--- /dev/null
+.. change::
+ :tags: usecase, sqlite
+ :tickets: 8804
+
+ Added support for reflection of expression-oriented WHERE criteria included
+ in indexes on the SQLite dialect, in a manner similar to that of the
+ PostgreSQL dialect. Pull request courtesy Tobias Pfeiffer.
from ... import processors
from ... import schema as sa_schema
from ... import sql
+from ... import text
from ... import types as sqltypes
from ... import util
from ...engine import default
)
indexes = []
+ # regular expression to extract the filter predicate of a partial
+ # index. this could fail to extract the predicate correctly on
+ # indexes created like
+ # CREATE INDEX i ON t (col || ') where') WHERE col <> ''
+ # but as this function does not support expression-based indexes
+ # this case does not occur.
+ partial_pred_re = re.compile(r"\)\s+where\s+(.+)", re.IGNORECASE)
+
+ if schema:
+ schema_expr = "%s." % self.identifier_preparer.quote_identifier(
+ schema
+ )
+ else:
+ schema_expr = ""
+
include_auto_indexes = kw.pop("include_auto_indexes", False)
for row in pragma_indexes:
# ignore implicit primary key index.
"sqlite_autoindex"
):
continue
- indexes.append(dict(name=row[1], column_names=[], unique=row[2]))
+ indexes.append(
+ dict(
+ name=row[1],
+ column_names=[],
+ unique=row[2],
+ dialect_options={},
+ )
+ )
+
+ # check partial indexes
+ if row[4]:
+ s = (
+ "SELECT sql FROM %(schema)ssqlite_master "
+ "WHERE name = ? "
+ "AND type = 'index'" % {"schema": schema_expr}
+ )
+ rs = connection.exec_driver_sql(s, (row[1],))
+ index_sql = rs.scalar()
+ predicate_match = partial_pred_re.search(index_sql)
+ if predicate_match is None:
+ # unless the regex is broken this case shouldn't happen
+ # because we know this is a partial index, so the
+ # definition sql should match the regex
+ util.warn(
+ "Failed to look up filter predicate of "
+ "partial index %s" % row[1]
+ )
+ else:
+ predicate = predicate_match.group(1)
+ indexes[-1]["dialect_options"]["sqlite_where"] = text(
+ predicate
+ )
# loop thru unique indexes to get the column names.
for idx in list(indexes):
break
else:
idx["column_names"].append(row[2])
+
+ indexes.sort(key=lambda d: d["name"] or "~") # sort None as last
return indexes
@reflection.cache
insp = inspect(connection)
expected = [
- {"name": "t_idx_2", "column_names": ["x"], "unique": False}
+ {
+ "name": "t_idx_2",
+ "column_names": ["x"],
+ "unique": False,
+ "dialect_options": {},
+ }
]
+
if testing.requires.index_reflects_included_columns.enabled:
expected[0]["include_columns"] = []
expected[0]["dialect_options"] = {
with expect_warnings(
"Skipped unsupported reflection of expression-based index t_idx"
):
- eq_(
- insp.get_indexes("t"),
- expected,
- )
+ eq_(insp.get_indexes("t"), expected)
@testing.requires.index_reflects_included_columns
def test_reflect_covering_index(self, metadata, connection):
"unique": 1,
"name": "sqlite_autoindex_o_1",
"column_names": ["foo"],
+ "dialect_options": {},
}
],
)
"unique": 0,
"name": u"ix_main_l_bar",
"column_names": [u"bar"],
+ "dialect_options": {},
}
],
)
+ def test_reflect_partial_indexes(self, connection):
+ connection.exec_driver_sql(
+ "create table foo_with_partial_index (x integer, y integer)"
+ )
+ connection.exec_driver_sql(
+ "create unique index ix_partial on "
+ "foo_with_partial_index (x) where y > 10"
+ )
+ connection.exec_driver_sql(
+ "create unique index ix_no_partial on "
+ "foo_with_partial_index (x)"
+ )
+ connection.exec_driver_sql(
+ "create unique index ix_partial2 on "
+ "foo_with_partial_index (x, y) where "
+ "y = 10 or abs(x) < 5"
+ )
+
+ inspector = inspect(connection)
+ indexes = inspector.get_indexes("foo_with_partial_index")
+ eq_(
+ indexes,
+ [
+ {
+ "unique": 1,
+ "name": "ix_no_partial",
+ "column_names": ["x"],
+ "dialect_options": {},
+ },
+ {
+ "unique": 1,
+ "name": "ix_partial",
+ "column_names": ["x"],
+ "dialect_options": {"sqlite_where": mock.ANY},
+ },
+ {
+ "unique": 1,
+ "name": "ix_partial2",
+ "column_names": ["x", "y"],
+ "dialect_options": {"sqlite_where": mock.ANY},
+ },
+ ],
+ )
+ eq_(indexes[1]["dialect_options"]["sqlite_where"].text, "y > 10")
+ eq_(
+ indexes[2]["dialect_options"]["sqlite_where"].text,
+ "y = 10 or abs(x) < 5",
+ )
+
def test_unique_constraint_named(self):
inspector = inspect(testing.db)
eq_(