]> git.ipfire.org Git - thirdparty/sqlalchemy/sqlalchemy.git/commitdiff
fixes #4966
authorRamonWill <ramonwilliams@hotmail.co.uk>
Mon, 10 Aug 2020 21:16:17 +0000 (22:16 +0100)
committerRamonWill <ramonwilliams@hotmail.co.uk>
Mon, 10 Aug 2020 21:16:17 +0000 (22:16 +0100)
doc/build/changelog/unreleased_14/4966.rst [new file with mode: 0644]
lib/sqlalchemy/dialects/mssql/base.py
lib/sqlalchemy/dialects/postgresql/base.py
test/dialect/mssql/test_reflection.py
test/dialect/postgresql/test_reflection.py

diff --git a/doc/build/changelog/unreleased_14/4966.rst b/doc/build/changelog/unreleased_14/4966.rst
new file mode 100644 (file)
index 0000000..8af1d17
--- /dev/null
@@ -0,0 +1,7 @@
+.. change::
+    :tags: mssql, usecase
+    :tickets: 4966
+
+    The :meth:`.Dialect.get_indexes` will now reflect the filter definitions
+    for Partial Indexes / Filtered Indexes on the PostgreSQL and MSSQL
+    dialects. Pull request courtesy Ramon Williams.
index 0ec6cf8a358218289ce2ffa540e6d3d058188030..c1b25fb63eb7f85e4dcf7794685103e4ec40676f 100644 (file)
@@ -2711,7 +2711,8 @@ class MSDialect(default.DefaultDialect):
 
         rp = connection.execution_options(future_result=True).execute(
             sql.text(
-                "select ind.index_id, ind.is_unique, ind.name "
+                "select ind.index_id, ind.is_unique, ind.name, "
+                "ind.filter_definition "
                 "from sys.indexes as ind join sys.tables as tab on "
                 "ind.object_id=tab.object_id "
                 "join sys.schemas as sch on sch.schema_id=tab.schema_id "
@@ -2731,6 +2732,7 @@ class MSDialect(default.DefaultDialect):
                 "name": row["name"],
                 "unique": row["is_unique"] == 1,
                 "column_names": [],
+                "dialect_options": {"mssql_where": row["filter_definition"]},
             }
         rp = connection.execution_options(future_result=True).execute(
             sql.text(
index 3bd7e62d53eebcbd6dbb6d3bea1ebdacba11d434..23d4750db055ca2245b712ef492592b45ae804f0 100644 (file)
@@ -3402,6 +3402,7 @@ class PGDialect(default.DefaultDialect):
                   ix.indisunique, ix.indexprs, ix.indpred,
                   a.attname, a.attnum, c.conrelid, ix.indkey::varchar,
                   ix.indoption::varchar, i.reloptions, am.amname,
+                  pg_get_expr(ix.indpred, ix.indrelid),
                   %s as indnkeyatts
               FROM
                   pg_class t
@@ -3452,6 +3453,7 @@ class PGDialect(default.DefaultDialect):
                 idx_option,
                 options,
                 amname,
+                filter_definition,
                 indnkeyatts,
             ) = row
 
@@ -3526,6 +3528,9 @@ class PGDialect(default.DefaultDialect):
                 if amname and amname != "btree":
                     index["amname"] = amname
 
+                if filter_definition:
+                    index["postgresql_where"] = filter_definition
+
         result = []
         for name, idx in indexes.items():
             entry = {
@@ -3548,6 +3553,10 @@ class PGDialect(default.DefaultDialect):
                 entry.setdefault("dialect_options", {})[
                     "postgresql_using"
                 ] = idx["amname"]
+            if "postgresql_where" in idx:
+                entry.setdefault("dialect_options", {})[
+                    "postgresql_where"
+                ] = idx["postgresql_where"]
             result.append(entry)
         return result
 
index 176d3d2ecbaa79daac0189c2988889258898869d..b092f7a38c6c2612754338f7706573b23c85929f 100644 (file)
@@ -319,6 +319,30 @@ class ReflectionTest(fixtures.TestBase, ComparesTables, AssertsCompiledSQL):
 
         eq_(set(list(t2.indexes)[0].columns), set([t2.c["x col"], t2.c.y]))
 
+    @testing.provide_metadata
+    def test_indexes_with_filtered(self):
+        metadata = self.metadata
+
+        t1 = Table(
+            "t",
+            metadata,
+            Column("id", Integer, primary_key=True),
+            Column("x", types.String(20)),
+            Column("y", types.Integer),
+        )
+        Index("idx_x", t1.c.x, mssql_where=t1.c.x == "test")
+        Index("idx_y", t1.c.y, mssql_where=t1.c.y >= 5)
+        metadata.create_all()
+        with testing.db.connect() as conn:
+            ind = testing.db.dialect.get_indexes(conn, "t", None)
+
+        filtered_indexes = []
+        for ix in ind:
+            if "dialect_options" in ix:
+                filtered_indexes.append(ix["dialect_options"]["mssql_where"])
+
+        eq_(sorted(filtered_indexes), ["([x]='test')", "([y]>=(5))"])
+
     @testing.provide_metadata
     def test_max_ident_in_varchar_not_present(self):
         """test [ticket:3504].
index ec9328c2fb1ea45a9fd2809329cfdbf9dd8bbb5c..6e728bda179c0d18ca879903113b3711ec2c5df1 100644 (file)
@@ -932,6 +932,49 @@ class ReflectionTest(fixtures.TestBase):
             ],
         )
 
+    @testing.provide_metadata
+    def test_index_reflection_partial(self):
+        """Reflect the filter defintion on partial indexes
+        """
+
+        metadata = self.metadata
+
+        t1 = Table(
+            "table1",
+            metadata,
+            Column("id", Integer, primary_key=True),
+            Column("name", String(20)),
+            Column("x", Integer),
+        )
+        metadata.create_all()
+        with testing.db.connect().execution_options(autocommit=True) as conn:
+            conn.exec_driver_sql("create index idx1 on table1 ((id || name))")
+            conn.exec_driver_sql(
+                "CREATE INDEX idx2 ON table1 (id) WHERE name = 'test'"
+            )
+            conn.exec_driver_sql(
+                "CREATE INDEX idx3 ON table1 (id) WHERE x >= 5"
+            )
+            with testing.expect_warnings(
+                "Skipped unsupported reflection of "
+                "expression-based index idx1",
+                "Predicate of partial index idx2 ignored during reflection",
+                "Predicate of partial index idx3 ignored during reflection",
+            ):
+                ind = testing.db.dialect.get_indexes(conn, t1, None)
+
+        partial_definitions = []
+        for ix in ind:
+            if "dialect_options" in ix:
+                partial_definitions.append(
+                    ix["dialect_options"]["postgresql_where"]
+                )
+
+        eq_(
+            sorted(partial_definitions),
+            ["((name)::text = 'test'::text)", "(x >= 5)"],
+        )
+
     @testing.fails_if("postgresql < 8.3", "index ordering not supported")
     @testing.provide_metadata
     def test_index_reflection_with_sorting(self):