:ticket:`3831`
+.. _change_4271:
+
+Expanding IN feature now supports empty lists
+---------------------------------------------
+
+The "expanding IN" feature introduced in version 1.2 at :ref:`change_3953` now
+supports empty lists passed to the :meth:`.ColumnOperators.in_` operator. The implementation
+for an empty list will produce an "empty set" expression that is specific to a target
+backend, such as "SELECT CAST(NULL AS INTEGER) WHERE 1!=1" for Postgresql,
+"SELECT 1 FROM (SELECT 1) as _empty_set WHERE 1!=1" for MySQL::
+
+ >>> from sqlalchemy import create_engine
+ >>> from sqlalchemy import select, literal_column, bindparam
+ >>> e = create_engine("postgresql://scott:tiger@localhost/test", echo=True)
+ >>> with e.connect() as conn:
+ ... conn.execute(
+ ... select([literal_column('1')]).
+ ... where(literal_column('1').in_(bindparam('q', expanding=True))),
+ ... q=[]
+ ... )
+ ...
+ SELECT 1 WHERE 1 IN (SELECT CAST(NULL AS INTEGER) WHERE 1!=1)
+
+:ticket:`4271`
Key Behavioral Changes - Core
=============================
+from sqlalchemy.dialects.mssql.base import MSDialect
+from sqlalchemy.dialects.oracle.base import OracleDialect
from .. import fixtures, config
-from ..assertions import eq_
+from ..assertions import eq_, in_
-from sqlalchemy import util
+from sqlalchemy import util, case, null, true, false, or_
from sqlalchemy import Integer, String, select, func, bindparam, union, tuple_
from sqlalchemy import testing
from sqlalchemy import literal_column
Table("some_table", metadata,
Column('id', Integer, primary_key=True),
Column('x', Integer),
- Column('y', Integer))
+ Column('y', Integer),
+ Column('z', String(50)))
@classmethod
def insert_data(cls):
config.db.execute(
cls.tables.some_table.insert(),
[
- {"id": 1, "x": 1, "y": 2},
- {"id": 2, "x": 2, "y": 3},
- {"id": 3, "x": 3, "y": 4},
- {"id": 4, "x": 4, "y": 5},
+ {"id": 1, "x": 1, "y": 2, "z": "z1"},
+ {"id": 2, "x": 2, "y": 3, "z": "z2"},
+ {"id": 3, "x": 3, "y": 4, "z": "z3"},
+ {"id": 4, "x": 4, "y": 5, "z": "z4"},
]
)
result
)
+ def test_multiple_empty_sets(self):
+ # test that any anonymous aliasing used by the dialect
+ # is fine with duplicates
+ table = self.tables.some_table
+
+ stmt = select([table.c.id]).where(
+ table.c.x.in_(bindparam('q', expanding=True))).where(
+ table.c.y.in_(bindparam('p', expanding=True))
+ ).order_by(table.c.id)
+
+ self._assert_result(
+ stmt,
+ [],
+ params={"q": [], "p": []},
+ )
+
def test_bound_in_scalar(self):
table = self.tables.some_table
table = self.tables.some_table
stmt = select([table.c.id]).where(
- tuple_(table.c.x, table.c.y).in_(bindparam('q', expanding=True))).order_by(table.c.id)
+ tuple_(table.c.x, table.c.y).in_(
+ bindparam('q', expanding=True))).order_by(table.c.id)
self._assert_result(
stmt,
params={"q": [(2, 3), (3, 4), (4, 5)]},
)
+ def test_empty_set_against_integer(self):
+ table = self.tables.some_table
+
+ stmt = select([table.c.id]).where(
+ table.c.x.in_(bindparam('q', expanding=True))).order_by(table.c.id)
+
+ self._assert_result(
+ stmt,
+ [],
+ params={"q": []},
+ )
+
+ def test_empty_set_against_integer_negation(self):
+ table = self.tables.some_table
+
+ stmt = select([table.c.id]).where(
+ table.c.x.notin_(bindparam('q', expanding=True))
+ ).order_by(table.c.id)
+
+ self._assert_result(
+ stmt,
+ [(1, ), (2, ), (3, ), (4, )],
+ params={"q": []},
+ )
+
+ def test_empty_set_against_string(self):
+ table = self.tables.some_table
+
+ stmt = select([table.c.id]).where(
+ table.c.z.in_(bindparam('q', expanding=True))).order_by(table.c.id)
+
+ self._assert_result(
+ stmt,
+ [],
+ params={"q": []},
+ )
+
+ def test_empty_set_against_string_negation(self):
+ table = self.tables.some_table
+
+ stmt = select([table.c.id]).where(
+ table.c.z.notin_(bindparam('q', expanding=True))
+ ).order_by(table.c.id)
+
+ self._assert_result(
+ stmt,
+ [(1, ), (2, ), (3, ), (4, )],
+ params={"q": []},
+ )
+
+ def test_null_in_empty_set_is_false(self):
+ stmt = select([
+ case(
+ [
+ (
+ null().in_(bindparam('foo', value=(), expanding=True)),
+ true()
+ )
+ ],
+ else_=false()
+ )
+ ])
+ in_(
+ config.db.execute(stmt).fetchone()[0],
+ (False, 0)
+ )
+
class LikeFunctionsTest(fixtures.TablesTest):
__backend__ = True