From: Mike Bayer Date: Tue, 16 Jul 2019 16:41:09 +0000 (-0400) Subject: Support tuple IN VALUES for SQLite, others X-Git-Tag: rel_1_3_6~4 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=19b6c152118229971492192ef29edb9d81078822;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Support tuple IN VALUES for SQLite, others Added support for composite (tuple) IN operators with SQLite, by rendering the VALUES keyword for this backend. As other backends such as DB2 are known to use the same syntax, the syntax is enabled in the base compiler using a dialect-level flag ``tuple_in_values``. The change also includes support for "empty IN tuple" expressions for SQLite when using "in_()" between a tuple value and an empty set. Fixes: #4766 Change-Id: I416e1af29b31d78f9ae06ec3c3a48ef6d6e813f5 (cherry picked from commit 88168db8e9a51ce438e06bfe792e758ed9297ab8) --- diff --git a/doc/build/changelog/unreleased_13/4766.rst b/doc/build/changelog/unreleased_13/4766.rst new file mode 100644 index 0000000000..afea19a185 --- /dev/null +++ b/doc/build/changelog/unreleased_13/4766.rst @@ -0,0 +1,11 @@ +.. change:: + :tags: usecase, sqlite + :tickets: 4766 + + Added support for composite (tuple) IN operators with SQLite, by rendering + the VALUES keyword for this backend. As other backends such as DB2 are + known to use the same syntax, the syntax is enabled in the base compiler + using a dialect-level flag ``tuple_in_values``. The change also includes + support for "empty IN tuple" expressions for SQLite when using "in_()" + between a tuple value and an empty set. + diff --git a/doc/build/orm/loading_relationships.rst b/doc/build/orm/loading_relationships.rst index 1a60693cd6..8a9a5148cc 100644 --- a/doc/build/orm/loading_relationships.rst +++ b/doc/build/orm/loading_relationships.rst @@ -835,17 +835,17 @@ as of the 1.2 series. Things to know about this kind of loading include: SQL Server. * As "selectin" loading relies upon IN, for a mapping with composite primary - keys, it must use the "tuple" form of IN, which looks like - ``WHERE (table.column_a, table.column_b) IN ((?, ?), (?, ?), (?, ?))``. - This syntax is not supported on every database; currently it is known - to be only supported by modern PostgreSQL and MySQL versions. Therefore - **selectin loading is not platform-agnostic for composite primary keys**. - There is no special logic in SQLAlchemy to check ahead of time which platforms - support this syntax or not; if run against a non-supporting platform (such - as SQLite), the database will return an error immediately. An advantage to SQLAlchemy - just running the SQL out for it to fail is that if a database like - SQLite does start supporting this syntax, it will work without any changes - to SQLAlchemy. + keys, it must use the "tuple" form of IN, which looks like ``WHERE + (table.column_a, table.column_b) IN ((?, ?), (?, ?), (?, ?))``. This syntax + is not supported on every database; within the dialects that are included + with SQLAlchemy, it is known to be supported by modern PostgreSQL, MySQL and + SQLite versions. Therefore **selectin loading is not platform-agnostic for + composite primary keys**. There is no special logic in SQLAlchemy to check + ahead of time which platforms support this syntax or not; if run against a + non-supporting platform, the database will return an error immediately. An + advantage to SQLAlchemy just running the SQL out for it to fail is that if a + particular database does start supporting this syntax, it will work without + any changes to SQLAlchemy. In general, "selectin" loading is probably superior to "subquery" eager loading in most ways, save for the syntax requirement with composite primary keys diff --git a/lib/sqlalchemy/dialects/sqlite/base.py b/lib/sqlalchemy/dialects/sqlite/base.py index d6a7139880..f8bf2c6208 100644 --- a/lib/sqlalchemy/dialects/sqlite/base.py +++ b/lib/sqlalchemy/dialects/sqlite/base.py @@ -1023,8 +1023,11 @@ class SQLiteCompiler(compiler.SQLCompiler): self.process(binary.right, **kw), ) - def visit_empty_set_expr(self, type_): - return "SELECT 1 FROM (SELECT 1) WHERE 1!=1" + def visit_empty_set_expr(self, element_types): + return "SELECT %s FROM (SELECT %s) WHERE 1!=1" % ( + ", ".join("1" for type_ in element_types or [INTEGER()]), + ", ".join("1" for type_ in element_types or [INTEGER()]), + ) class SQLiteDDLCompiler(compiler.DDLCompiler): @@ -1391,6 +1394,7 @@ class SQLiteDialect(default.DefaultDialect): supports_empty_insert = False supports_cast = True supports_multivalues_insert = True + tuple_in_values = True default_paramstyle = "qmark" execution_ctx_cls = SQLiteExecutionContext diff --git a/lib/sqlalchemy/engine/default.py b/lib/sqlalchemy/engine/default.py index f6c30cbf47..b56755d62c 100644 --- a/lib/sqlalchemy/engine/default.py +++ b/lib/sqlalchemy/engine/default.py @@ -75,6 +75,8 @@ class DefaultDialect(interfaces.Dialect): supports_simple_order_by_label = True + tuple_in_values = False + engine_config_types = util.immutabledict( [ ("convert_unicode", util.bool_or_str("force")), @@ -812,7 +814,9 @@ class DefaultExecutionContext(interfaces.ExecutionContext): for i, tuple_element in enumerate(values, 1) for j, value in enumerate(tuple_element, 1) ] - replacement_expressions[name] = ", ".join( + replacement_expressions[name] = ( + "VALUES " if self.dialect.tuple_in_values else "" + ) + ", ".join( "(%s)" % ", ".join( self.compiled.bindtemplate diff --git a/lib/sqlalchemy/sql/compiler.py b/lib/sqlalchemy/sql/compiler.py index ba43d52783..29376a59c8 100644 --- a/lib/sqlalchemy/sql/compiler.py +++ b/lib/sqlalchemy/sql/compiler.py @@ -966,13 +966,17 @@ class SQLCompiler(Compiled): sep = " " else: sep = OPERATORS[clauselist.operator] - return sep.join( + + text = sep.join( s for s in ( c._compiler_dispatch(self, **kw) for c in clauselist.clauses ) if s ) + if clauselist._tuple_values and self.dialect.tuple_in_values: + text = "VALUES " + text + return text def visit_case(self, clause, **kwargs): x = "CASE " diff --git a/lib/sqlalchemy/sql/default_comparator.py b/lib/sqlalchemy/sql/default_comparator.py index 9a12b84cd9..0f0fdcf2bd 100644 --- a/lib/sqlalchemy/sql/default_comparator.py +++ b/lib/sqlalchemy/sql/default_comparator.py @@ -220,7 +220,12 @@ def _in_impl(expr, op, seq_or_selectable, negate_op, **kw): ) return _boolean_compare( - expr, op, ClauseList(*args).self_group(against=op), negate=negate_op + expr, + op, + ClauseList(_tuple_values=isinstance(expr, Tuple), *args).self_group( + against=op + ), + negate=negate_op, ) diff --git a/lib/sqlalchemy/sql/elements.py b/lib/sqlalchemy/sql/elements.py index b976428ed7..2a54529afd 100644 --- a/lib/sqlalchemy/sql/elements.py +++ b/lib/sqlalchemy/sql/elements.py @@ -1880,6 +1880,7 @@ class ClauseList(ClauseElement): self.operator = kwargs.pop("operator", operators.comma_op) self.group = kwargs.pop("group", True) self.group_contents = kwargs.pop("group_contents", True) + self._tuple_values = kwargs.pop("_tuple_values", False) text_converter = kwargs.pop( "_literal_as_text", _expression_literal_as_text ) @@ -1962,6 +1963,8 @@ class ClauseList(ClauseElement): class BooleanClauseList(ClauseList, ColumnElement): __visit_name__ = "clauselist" + _tuple_values = False + def __init__(self, *arg, **kw): raise NotImplementedError( "BooleanClauseList has a private constructor" @@ -2107,13 +2110,15 @@ class Tuple(ClauseList, ColumnElement): [(1, 2), (5, 12), (10, 19)] ) + .. versionchanged:: 1.3.6 Added support for SQLite IN tuples. + .. warning:: - The composite IN construct is not supported by all backends, - and is currently known to work on PostgreSQL and MySQL, - but not SQLite. Unsupported backends will raise - a subclass of :class:`~sqlalchemy.exc.DBAPIError` when such - an expression is invoked. + The composite IN construct is not supported by all backends, and is + currently known to work on PostgreSQL, MySQL, and SQLite. + Unsupported backends will raise a subclass of + :class:`~sqlalchemy.exc.DBAPIError` when such an expression is + invoked. """ diff --git a/test/dialect/test_sqlite.py b/test/dialect/test_sqlite.py index b9a5c28c1b..c9332b7fac 100644 --- a/test/dialect/test_sqlite.py +++ b/test/dialect/test_sqlite.py @@ -8,6 +8,7 @@ from sqlalchemy import and_ from sqlalchemy import bindparam from sqlalchemy import CheckConstraint from sqlalchemy import Column +from sqlalchemy import column from sqlalchemy import create_engine from sqlalchemy import DefaultClause from sqlalchemy import event @@ -26,6 +27,7 @@ from sqlalchemy import sql from sqlalchemy import Table from sqlalchemy import testing from sqlalchemy import text +from sqlalchemy import tuple_ from sqlalchemy import types as sqltypes from sqlalchemy import UniqueConstraint from sqlalchemy import util @@ -962,6 +964,12 @@ class SQLTest(fixtures.TestBase, AssertsCompiledSQL): dialect=sqlite.dialect(), ) + def test_in_tuple(self): + self.assert_compile( + tuple_(column("q"), column("p")).in_([(1, 2), (3, 4)]), + "(q, p) IN (VALUES (?, ?), (?, ?))", + ) + class OnConflictDDLTest(fixtures.TestBase, AssertsCompiledSQL): diff --git a/test/requirements.py b/test/requirements.py index 059ce01871..54b2afb6f9 100644 --- a/test/requirements.py +++ b/test/requirements.py @@ -251,7 +251,12 @@ class DefaultRequirements(SuiteRequirements): @property def tuple_in(self): - return only_on(["mysql", "postgresql"]) + def _sqlite_tuple_in(config): + return against( + config, "sqlite" + ) and config.db.dialect.dbapi.sqlite_version_info >= (3, 15, 0) + + return only_on(["mysql", "postgresql", _sqlite_tuple_in]) @property def independent_cursors(self): diff --git a/test/sql/test_compiler.py b/test/sql/test_compiler.py index 9d6e17a1d2..37e5f980d2 100644 --- a/test/sql/test_compiler.py +++ b/test/sql/test_compiler.py @@ -2465,6 +2465,15 @@ class SelectTest(fixtures.TestBase, AssertsCompiledSQL): "((:param_1, :param_2), (:param_3, :param_4))", ) + dialect = default.DefaultDialect() + dialect.tuple_in_values = True + self.assert_compile( + tuple_(table1.c.myid, table1.c.name).in_([(1, "foo"), (5, "bar")]), + "(mytable.myid, mytable.name) IN " + "(VALUES (:param_1, :param_2), (:param_3, :param_4))", + dialect=dialect, + ) + self.assert_compile( tuple_(table1.c.myid, table1.c.name).in_( [tuple_(table2.c.otherid, table2.c.othername)] @@ -2489,6 +2498,16 @@ class SelectTest(fixtures.TestBase, AssertsCompiledSQL): "(mytable.myid, mytable.name) IN ([EXPANDING_foo])", ) + dialect = default.DefaultDialect() + dialect.tuple_in_values = True + self.assert_compile( + tuple_(table1.c.myid, table1.c.name).in_( + bindparam("foo", expanding=True) + ), + "(mytable.myid, mytable.name) IN ([EXPANDING_foo])", + dialect=dialect, + ) + self.assert_compile( table1.c.myid.in_(bindparam("foo", expanding=True)), "mytable.myid IN ([EXPANDING_foo])",