Postgresql index would be reflected in the wrong order.
Courtesy Roman Podolyaka.
+ :tags: bug, sql
+ :tickets: 2746, 2668
+
+ Multiple fixes to the correlation behavior of
+ :class:`.Select` constructs, first introduced in 0.8.0:
+
+ * To satisfy the use case where FROM entries should be
+ correlated outwards to a SELECT that encloses another,
+ which then encloses this one, correlation now works
+ across multiple levels when explicit correlation is
+ established via :meth:`.Select.correlate`, provided
+ that the target select is somewhere along the chain
+ contained by a WHERE/ORDER BY/columns clause, not
+ just nested FROM clauses. This makes
+ :meth:`.Select.correlate` act more compatibly to
+ that of 0.7 again while still maintaining the new
+ "smart" correlation.
+
+ * When explicit correlation is not used, the usual
+ "implicit" correlation limits its behavior to just
+ the immediate enclosing SELECT, to maximize compatibility
+ with 0.7 applications, and also prevents correlation
+ across nested FROMs in this case, maintaining compatibility
+ with 0.8.0/0.8.1.
+
+ * The :meth:`.Select.correlate_except` method was not
+ preventing the given FROM clauses from correlation in
+ all cases, and also would cause FROM clauses to be incorrectly
+ omitted entirely (more like what 0.7 would do),
+ this has been fixed.
+
+ * Calling `select.correlate_except(None)` will enter
+ all FROM clauses into correlation as would be expected.
+
.. change::
:tags: bug, ext
('wendy',)
{stop}[(u'wendy',)]
+We can also control correlation via exclusion, using the :meth:`.Select.correlate_except`
+method. Such as, we can write our SELECT for the ``users`` table
+by telling it to correlate all FROM clauses except for ``users``:
+
+.. sourcecode:: pycon+sql
+
+ >>> stmt = select([users.c.id]).\
+ ... where(users.c.id == addresses.c.user_id).\
+ ... where(users.c.name == 'jack').\
+ ... correlate_except(users)
+ >>> enclosing_stmt = select(
+ ... [users.c.name, addresses.c.email_address]).\
+ ... select_from(users.join(addresses)).\
+ ... where(users.c.id == stmt)
+ >>> conn.execute(enclosing_stmt).fetchall() # doctest: +NORMALIZE_WHITESPACE
+ {opensql}SELECT users.name, addresses.email_address
+ FROM users JOIN addresses ON users.id = addresses.user_id
+ WHERE users.id = (SELECT users.id
+ FROM users
+ WHERE users.id = addresses.user_id AND users.name = ?)
+ ('jack',)
+ {stop}[(u'jack', u'jack@yahoo.com'), (u'jack', u'jack@msn.com')]
+
Ordering, Grouping, Limiting, Offset...ing...
---------------------------------------------
:doc:`orm/session`
+ columns clause
+ The portion of the ``SELECT`` statement which enumerates the
+ SQL expressions to be returned in the result set. The expressions
+ follow the ``SELECT`` keyword directly and are a comma-separated
+ list of individual expressions.
+
+ E.g.:
+
+ .. sourcecode:: sql
+
+ SELECT user_account.name, user_account.email
+ FROM user_account WHERE user_account.name = 'fred'
+
+ Above, the list of columns ``user_acount.name``,
+ ``user_account.email`` is the columns clause of the ``SELECT``.
+
+ WHERE clause
+ The portion of the ``SELECT`` statement which indicates criteria
+ by which rows should be filtered. It is a single SQL expression
+ which follows the keyword ``WHERE``.
+
+ .. sourcecode:: sql
+
+ SELECT user_account.name, user_account.email
+ FROM user_account
+ WHERE user_account.name = 'fred' AND user_account.status = 'E'
+
+ Above, the phrase ``WHERE user_account.name = 'fred' AND user_account.status = 'E'``
+ comprises the WHERE clause of the ``SELECT``.
+
+ FROM clause
+ The portion of the ``SELECT`` statement which incicates the initial
+ source of rows.
+
+ A simple ``SELECT`` will feature one or more table names in its
+ FROM clause. Multiple sources are separated by a comma:
+
+ .. sourcecode:: sql
+
+ SELECT user.name, address.email_address
+ FROM user, address
+ WHERE user.id=address.user_id
+
+ The FROM clause is also where explicit joins are specified. We can
+ rewrite the above ``SELECT`` using a single ``FROM`` element which consists
+ of a ``JOIN`` of the two tables:
+
+ .. sourcecode:: sql
+
+ SELECT user.name, address.email_address
+ FROM user JOIN address ON user.id=address.user_id
+
+
+ subquery
+ Refers to a ``SELECT`` statement that is embedded within an enclosing
+ ``SELECT``.
+
+ A subquery comes in two general flavors, one known as a "scalar select"
+ which specifically must return exactly one row and one column, and the
+ other form which acts as a "derived table" and serves as a source of
+ rows for the FROM clause of another select. A scalar select is eligble
+ to be placed in the :term:`WHERE clause`, :term:`columns clause`,
+ ORDER BY clause or HAVING clause of the enclosing select, whereas the
+ derived table form is eligible to be placed in the FROM clause of the
+ enclosing ``SELECT``.
+
+ Examples:
+
+ 1. a scalar subquery placed in the :term:`columns clause` of an enclosing
+ ``SELECT``. The subquery in this example is a :term:`correlated subquery` because part
+ of the rows which it selects from are given via the enclosing statement.
+
+ .. sourcecode:: sql
+
+ SELECT id, (SELECT name FROM address WHERE address.user_id=user.id)
+ FROM user
+
+ 2. a scalar subquery placed in the :term:`WHERE clause` of an enclosing
+ ``SELECT``. This subquery in this example is not correlated as it selects a fixed result.
+
+ .. sourcecode:: sql
+
+ SELECT id, name FROM user
+ WHERE status=(SELECT status_id FROM status_code WHERE code='C')
+
+ 3. a derived table subquery placed in the :term:`FROM clause` of an enclosing
+ ``SELECT``. Such a subquery is almost always given an alias name.
+
+ .. sourcecode:: sql
+
+ SELECT user.id, user.name, ad_subq.email_address
+ FROM
+ user JOIN
+ (select user_id, email_address FROM address WHERE address_type='Q') AS ad_subq
+ ON user.id = ad_subq.user_id
+
correlates
correlated subquery
correlated subqueries
table is recieved from the enclosing query, where each row selected from
``user_account`` results in a distinct execution of the subquery.
- A correlated subquery is nearly always present in the :term:`WHERE clause`
- or :term:`columns clause` of the enclosing ``SELECT`` statement, and never
- in the :term:`FROM clause`; this is because
- the correlation can only proceed once the original source rows from the enclosing
- statement's FROM clause are available.
+ A correlated subquery is in most cases present in the :term:`WHERE clause`
+ or :term:`columns clause` of the immediately enclosing ``SELECT``
+ statement, as well as in the ORDER BY or HAVING clause.
+
+ In less common cases, a correlated subquery may be present in the
+ :term:`FROM clause` of an enclosing ``SELECT``; in these cases the
+ correlation is typically due to the enclosing ``SELECT`` itself being
+ enclosed in the WHERE,
+ ORDER BY, columns or HAVING clause of another ``SELECT``, such as:
+
+ .. sourcecode:: sql
+
+ SELECT parent.id FROM parent
+ WHERE EXISTS (
+ SELECT * FROM (
+ SELECT child.id AS id, child.parent_id AS parent_id, child.pos AS pos
+ FROM child
+ WHERE child.parent_id = parent.id ORDER BY child.pos
+ LIMIT 3)
+ WHERE id = 7)
+
+ Correlation from one ``SELECT`` directly to one which encloses the correlated
+ query via its ``FROM``
+ clause is not possible, because the correlation can only proceed once the
+ original source rows from the enclosing statement's FROM clause are available.
if not getattr(select, '_oracle_visit', None):
if not self.dialect.use_ansi:
- if self.stack and 'from' in self.stack[-1]:
- existingfroms = self.stack[-1]['from']
- else:
- existingfroms = None
-
- froms = select._get_display_froms(existingfroms)
+ froms = self._display_froms_for_select(
+ select, kwargs.get('asfrom', False))
whereclause = self._get_nonansi_join_whereclause(froms)
if whereclause is not None:
select = select.where(whereclause)
def visit_compound_select(self, cs, asfrom=False,
parens=True, compound_index=0, **kwargs):
- entry = self.stack and self.stack[-1] or {}
- self.stack.append({'from': entry.get('from', None),
- 'iswrapper': not entry})
+ toplevel = not self.stack
+ entry = self._default_stack_entry if toplevel else self.stack[-1]
+
+ self.stack.append(
+ {
+ 'correlate_froms': entry['correlate_froms'],
+ 'iswrapper': toplevel,
+ 'asfrom_froms': entry['asfrom_froms']
+ })
keyword = self.compound_keywords.get(cs.keyword)
self.limit_clause(cs) or ""
if self.ctes and \
- compound_index == 0 and not entry:
+ compound_index == 0 and toplevel:
text = self._render_cte_clause() + text
self.stack.pop(-1)
def get_crud_hint_text(self, table, text):
return None
+
+
+ _default_stack_entry = util.immutabledict([
+ ('iswrapper', False),
+ ('correlate_froms', frozenset()),
+ ('asfrom_froms', frozenset())
+ ])
+
+ def _display_froms_for_select(self, select, asfrom):
+ # utility method to help external dialects
+ # get the correct from list for a select.
+ # specifically the oracle dialect needs this feature
+ # right now.
+ toplevel = not self.stack
+ entry = self._default_stack_entry if toplevel else self.stack[-1]
+
+ correlate_froms = entry['correlate_froms']
+ asfrom_froms = entry['asfrom_froms']
+
+ if asfrom:
+ froms = select._get_display_froms(
+ explicit_correlate_froms=\
+ correlate_froms.difference(asfrom_froms),
+ implicit_correlate_froms=())
+ else:
+ froms = select._get_display_froms(
+ explicit_correlate_froms=correlate_froms,
+ implicit_correlate_froms=asfrom_froms)
+ return froms
+
def visit_select(self, select, asfrom=False, parens=True,
iswrapper=False, fromhints=None,
compound_index=0,
force_result_map=False,
- positional_names=None, **kwargs):
- entry = self.stack and self.stack[-1] or {}
+ positional_names=None,
+ **kwargs):
- existingfroms = entry.get('from', None)
+ toplevel = not self.stack
+ entry = self._default_stack_entry if toplevel else self.stack[-1]
- froms = select._get_display_froms(existingfroms, asfrom=asfrom)
-
- correlate_froms = set(sql._from_objects(*froms))
-
- # TODO: might want to propagate existing froms for
- # select(select(select)) where innermost select should correlate
- # to outermost if existingfroms: correlate_froms =
- # correlate_froms.union(existingfroms)
populate_result_map = force_result_map or (
compound_index == 0 and (
- not entry or \
- entry.get('iswrapper', False)
+ toplevel or \
+ entry['iswrapper']
)
)
- self.stack.append({'from': correlate_froms,
- 'iswrapper': iswrapper})
+
+ correlate_froms = entry['correlate_froms']
+ asfrom_froms = entry['asfrom_froms']
+
+ if asfrom:
+ froms = select._get_display_froms(
+ explicit_correlate_froms=
+ correlate_froms.difference(asfrom_froms),
+ implicit_correlate_froms=())
+ else:
+ froms = select._get_display_froms(
+ explicit_correlate_froms=correlate_froms,
+ implicit_correlate_froms=asfrom_froms)
+
+
+ new_correlate_froms = set(sql._from_objects(*froms))
+ all_correlate_froms = new_correlate_froms.union(correlate_froms)
+
+ new_entry = {
+ 'asfrom_froms': new_correlate_froms,
+ 'iswrapper': iswrapper,
+ 'correlate_froms': all_correlate_froms
+ }
+ self.stack.append(new_entry)
column_clause_args = kwargs.copy()
column_clause_args.update({
text += self.for_update_clause(select)
if self.ctes and \
- compound_index == 0 and not entry:
+ compound_index == 0 and toplevel:
text = self._render_cte_clause() + text
self.stack.pop(-1)
for t in extra_froms)
def visit_update(self, update_stmt, **kw):
- self.stack.append({'from': set([update_stmt.table])})
+ self.stack.append(
+ {'correlate_froms': set([update_stmt.table]),
+ "iswrapper": False,
+ "asfrom_froms": set([update_stmt.table])})
self.isupdate = True
return values
def visit_delete(self, delete_stmt, **kw):
- self.stack.append({'from': set([delete_stmt.table])})
+ self.stack.append({'correlate_froms': set([delete_stmt.table]),
+ "iswrapper": False,
+ "asfrom_froms": set([delete_stmt.table])})
self.isdelete = True
text = "DELETE "
return set(elem for elem in a
if all_overlap.intersection(elem._cloned_set))
+def _cloned_difference(a, b):
+ all_overlap = set(_expand_cloned(a)).intersection(_expand_cloned(b))
+ return set(elem for elem in a
+ if not all_overlap.intersection(elem._cloned_set))
def _from_objects(*elements):
return itertools.chain(*[element._from_objects for element in elements])
_distinct = False
_from_cloned = None
_correlate = ()
- _correlate_except = ()
+ _correlate_except = None
_memoized_property = SelectBase._memoized_property
def __init__(self,
return froms
- def _get_display_froms(self, existing_froms=None, asfrom=False):
+ def _get_display_froms(self, explicit_correlate_froms=None,
+ implicit_correlate_froms=None):
"""Return the full list of 'from' clauses to be displayed.
Takes into account a set of existing froms which may be
"""
froms = self._froms
- toremove = set(itertools.chain(*[f._hide_froms for f in froms]))
+ toremove = set(itertools.chain(*[
+ _expand_cloned(f._hide_froms)
+ for f in froms]))
if toremove:
# if we're maintaining clones of froms,
# add the copies out to the toremove list. only include
# using a list to maintain ordering
froms = [f for f in froms if f not in toremove]
- if not asfrom:
- if self._correlate:
+ if self._correlate:
+ to_correlate = self._correlate
+ if to_correlate:
froms = [
f for f in froms if f not in
_cloned_intersection(
- _cloned_intersection(froms, existing_froms or ()),
- self._correlate
- )
- ]
- if self._correlate_except:
- froms = [
- f for f in froms if f in
- _cloned_intersection(
- froms,
- self._correlate_except
+ _cloned_intersection(froms, explicit_correlate_froms or ()),
+ to_correlate
)
]
- if self._auto_correlate and existing_froms and len(froms) > 1:
- froms = [
- f for f in froms if f not in
- _cloned_intersection(froms, existing_froms)
- ]
+ if self._correlate_except is not None:
+
+ froms = [
+ f for f in froms if f not in
+ _cloned_difference(
+ _cloned_intersection(froms, explicit_correlate_froms or ()),
+ self._correlate_except
+ )
+ ]
- if not len(froms):
- raise exc.InvalidRequestError("Select statement '%s"
- "' returned no FROM clauses due to "
- "auto-correlation; specify "
- "correlate(<tables>) to control "
- "correlation manually." % self)
+ if self._auto_correlate and \
+ implicit_correlate_froms and \
+ len(froms) > 1:
+
+ froms = [
+ f for f in froms if f not in
+ _cloned_intersection(froms, implicit_correlate_froms)
+ ]
+
+ if not len(froms):
+ raise exc.InvalidRequestError("Select statement '%s"
+ "' returned no FROM clauses due to "
+ "auto-correlation; specify "
+ "correlate(<tables>) to control "
+ "correlation manually." % self)
return froms
@_generative
def correlate(self, *fromclauses):
- """return a new select() construct which will correlate the given FROM
- clauses to that of an enclosing select(), if a match is found.
-
- By "match", the given fromclause must be present in this select's
- list of FROM objects and also present in an enclosing select's list of
- FROM objects.
-
- Calling this method turns off the select's default behavior of
- "auto-correlation". Normally, select() auto-correlates all of its FROM
- clauses to those of an embedded select when compiled.
-
- If the fromclause is None, correlation is disabled for the returned
- select().
+ """return a new :class:`.Select` which will correlate the given FROM
+ clauses to that of an enclosing :class:`.Select`.
+
+ Calling this method turns off the :class:`.Select` object's
+ default behavior of "auto-correlation". Normally, FROM elements
+ which appear in a :class:`.Select` that encloses this one via
+ its :term:`WHERE clause`, ORDER BY, HAVING or
+ :term:`columns clause` will be omitted from this :class:`.Select`
+ object's :term:`FROM clause`.
+ Setting an explicit correlation collection using the
+ :meth:`.Select.correlate` method provides a fixed list of FROM objects
+ that can potentially take place in this process.
+
+ When :meth:`.Select.correlate` is used to apply specific FROM clauses
+ for correlation, the FROM elements become candidates for
+ correlation regardless of how deeply nested this :class:`.Select`
+ object is, relative to an enclosing :class:`.Select` which refers to
+ the same FROM object. This is in contrast to the behavior of
+ "auto-correlation" which only correlates to an immediate enclosing
+ :class:`.Select`. Multi-level correlation ensures that the link
+ between enclosed and enclosing :class:`.Select` is always via
+ at least one WHERE/ORDER BY/HAVING/columns clause in order for
+ correlation to take place.
+
+ If ``None`` is passed, the :class:`.Select` object will correlate
+ none of its FROM entries, and all will render unconditionally
+ in the local FROM clause.
+
+ :param \*fromclauses: a list of one or more :class:`.FromClause`
+ constructs, or other compatible constructs (i.e. ORM-mapped
+ classes) to become part of the correlate collection.
+
+ .. versionchanged:: 0.8.0 ORM-mapped classes are accepted by
+ :meth:`.Select.correlate`.
+
+ .. versionchanged:: 0.8.0 The :meth:`.Select.correlate` method no
+ longer unconditionally removes entries from the FROM clause; instead,
+ the candidate FROM entries must also be matched by a FROM entry
+ located in an enclosing :class:`.Select`, which ultimately encloses
+ this one as present in the WHERE clause, ORDER BY clause, HAVING
+ clause, or columns clause of an enclosing :meth:`.Select`.
+
+ .. versionchanged:: 0.8.2 explicit correlation takes place
+ via any level of nesting of :class:`.Select` objects; in previous
+ 0.8 versions, correlation would only occur relative to the immediate
+ enclosing :class:`.Select` construct.
.. seealso::
@_generative
def correlate_except(self, *fromclauses):
- """"Return a new select() construct which will auto-correlate
- on FROM clauses of enclosing selectables, except for those FROM
- clauses specified here.
+ """return a new :class:`.Select` which will omit the given FROM
+ clauses from the auto-correlation process.
+
+ Calling :meth:`.Select.correlate_except` turns off the
+ :class:`.Select` object's default behavior of
+ "auto-correlation" for the given FROM elements. An element
+ specified here will unconditionally appear in the FROM list, while
+ all other FROM elements remain subject to normal auto-correlation
+ behaviors.
+
+ .. versionchanged:: 0.8.2 The :meth:`.Select.correlate_except`
+ method was improved to fully prevent FROM clauses specified here
+ from being omitted from the immediate FROM clause of this
+ :class:`.Select`.
+
+ If ``None`` is passed, the :class:`.Select` object will correlate
+ all of its FROM entries.
+
+ .. versionchanged:: 0.8.2 calling ``correlate_except(None)`` will
+ correctly auto-correlate all FROM clauses.
+
+ :param \*fromclauses: a list of one or more :class:`.FromClause`
+ constructs, or other compatible constructs (i.e. ORM-mapped
+ classes) to become part of the correlate-exception collection.
.. seealso::
:ref:`correlated_subqueries`
"""
+
self._auto_correlate = False
if fromclauses and fromclauses[0] is None:
self._correlate_except = ()
else:
- self._correlate_except = set(self._correlate_except).union(
+ self._correlate_except = set(self._correlate_except or ()).union(
_interpret_as_from(f) for f in fromclauses)
def append_correlation(self, fromclause):
class OperatorTest(QueryTest, AssertsCompiledSQL):
"""test sql.Comparator implementation for MapperProperties"""
- def _test(self, clause, expected):
- self.assert_compile(clause, expected, dialect=default.DefaultDialect())
+ __dialect__ = 'default'
+
+ def _test(self, clause, expected, entity=None):
+ dialect = default.DefaultDialect()
+ if entity is not None:
+ # specify a lead entity, so that when we are testing
+ # correlation, the correlation actually happens
+ sess = Session()
+ lead = sess.query(entity)
+ context = lead._compile_context()
+ context.statement.use_labels = True
+ lead = context.statement.compile(dialect=dialect)
+ expected = (str(lead) + " WHERE " + expected).replace("\n", "")
+ clause = sess.query(entity).filter(clause)
+ self.assert_compile(clause, expected)
def test_arithmetic(self):
User = self.classes.User
self._test(User.addresses.any(Address.id==17),
"EXISTS (SELECT 1 "
"FROM addresses "
- "WHERE users.id = addresses.user_id AND addresses.id = :id_1)"
+ "WHERE users.id = addresses.user_id AND addresses.id = :id_1)",
+ entity=User
)
u7 = User(id=7)
self._test(Address.user == u7, ":param_1 = addresses.user_id")
- self._test(Address.user != u7, "addresses.user_id != :user_id_1 OR addresses.user_id IS NULL")
+ self._test(Address.user != u7,
+ "addresses.user_id != :user_id_1 OR addresses.user_id IS NULL")
self._test(Address.user == None, "addresses.user_id IS NULL")
self._test(Address.user != None, "addresses.user_id IS NOT NULL")
- def test_foo(self):
- Node = self.classes.Node
- nalias = aliased(Node)
- self._test(
- nalias.parent.has(Node.data=='some data'),
- "EXISTS (SELECT 1 FROM nodes WHERE nodes.id = nodes_1.parent_id AND nodes.data = :data_1)"
- )
def test_selfref_relationship(self):
+
Node = self.classes.Node
nalias = aliased(Node)
self._test(
Node.children.any(Node.data=='n1'),
"EXISTS (SELECT 1 FROM nodes AS nodes_1 WHERE "
- "nodes.id = nodes_1.parent_id AND nodes_1.data = :data_1)"
+ "nodes.id = nodes_1.parent_id AND nodes_1.data = :data_1)",
+ entity=Node
)
# needs autoaliasing
self._test(
- Node.children==None,
- "NOT (EXISTS (SELECT 1 FROM nodes AS nodes_1 WHERE nodes.id = nodes_1.parent_id))"
+ Node.children == None,
+ "NOT (EXISTS (SELECT 1 FROM nodes AS nodes_1 "
+ "WHERE nodes.id = nodes_1.parent_id))",
+ entity=Node
)
self._test(
- Node.parent==None,
+ Node.parent == None,
"nodes.parent_id IS NULL"
)
self._test(
- nalias.parent==None,
+ nalias.parent == None,
"nodes_1.parent_id IS NULL"
)
self._test(
- nalias.children==None,
- "NOT (EXISTS (SELECT 1 FROM nodes WHERE nodes_1.id = nodes.parent_id))"
+ nalias.children == None,
+ "NOT (EXISTS (SELECT 1 FROM nodes WHERE nodes_1.id = nodes.parent_id))",
+ entity=nalias
)
self._test(
nalias.children.any(Node.data=='some data'),
"EXISTS (SELECT 1 FROM nodes WHERE "
- "nodes_1.id = nodes.parent_id AND nodes.data = :data_1)")
+ "nodes_1.id = nodes.parent_id AND nodes.data = :data_1)",
+ entity=nalias)
- # fails, but I think I want this to fail
+ # this fails because self-referential any() is auto-aliasing;
+ # the fact that we use "nalias" here means we get two aliases.
#self._test(
- # Node.children.any(nalias.data=='some data'),
+ # Node.children.any(nalias.data == 'some data'),
# "EXISTS (SELECT 1 FROM nodes AS nodes_1 WHERE "
- # "nodes.id = nodes_1.parent_id AND nodes_1.data = :data_1)"
+ # "nodes.id = nodes_1.parent_id AND nodes_1.data = :data_1)",
+ # entity=Node
# )
self._test(
- nalias.parent.has(Node.data=='some data'),
- "EXISTS (SELECT 1 FROM nodes WHERE nodes.id = nodes_1.parent_id AND nodes.data = :data_1)"
+ nalias.parent.has(Node.data == 'some data'),
+ "EXISTS (SELECT 1 FROM nodes WHERE nodes.id = nodes_1.parent_id "
+ "AND nodes.data = :data_1)",
+ entity=nalias
)
+
self._test(
- Node.parent.has(Node.data=='some data'),
- "EXISTS (SELECT 1 FROM nodes AS nodes_1 WHERE nodes_1.id = nodes.parent_id AND nodes_1.data = :data_1)"
+ Node.parent.has(Node.data == 'some data'),
+ "EXISTS (SELECT 1 FROM nodes AS nodes_1 WHERE "
+ "nodes_1.id = nodes.parent_id AND nodes_1.data = :data_1)",
+ entity=Node
)
self._test(
nalias.children.contains(Node(id=7)), "nodes_1.id = :param_1"
)
+ def test_multilevel_any(self):
+ User, Address, Dingaling = \
+ self.classes.User, self.classes.Address, self.classes.Dingaling
+ sess = Session()
+
+ q = sess.query(User).filter(
+ User.addresses.any(
+ and_(Address.id == Dingaling.address_id,
+ Dingaling.data == 'x')))
+ # new since #2746 - correlate_except() now takes context into account
+ # so its usage in any() is not as disrupting.
+ self.assert_compile(q,
+ "SELECT users.id AS users_id, users.name AS users_name "
+ "FROM users "
+ "WHERE EXISTS (SELECT 1 "
+ "FROM addresses, dingalings "
+ "WHERE users.id = addresses.user_id AND "
+ "addresses.id = dingalings.address_id AND "
+ "dingalings.data = :data_1)"
+ )
+
def test_op(self):
User = self.classes.User
"SELECT t1.a, t2.a FROM t1, t2 WHERE t2.a = "
"(SELECT t1.a WHERE t1.a = t2.a)")
- def _assert_where_backwards_correlated(self, stmt):
- self.assert_compile(
- stmt,
- "SELECT t2.a FROM t2 WHERE t2.a = "
- "(SELECT t1.a FROM t2 WHERE t1.a = t2.a)")
+ # note there's no more "backwards" correlation after
+ # we've done #2746
+ #def _assert_where_backwards_correlated(self, stmt):
+ # self.assert_compile(
+ # stmt,
+ # "SELECT t2.a FROM t2 WHERE t2.a = "
+ # "(SELECT t1.a FROM t2 WHERE t1.a = t2.a)")
+
+ #def _assert_column_backwards_correlated(self, stmt):
+ # self.assert_compile(stmt,
+ # "SELECT t2.a, (SELECT t1.a FROM t2 WHERE t1.a = t2.a) "
+ # "AS anon_1 FROM t2")
def _assert_column_correlated(self, stmt):
self.assert_compile(stmt,
"SELECT t1.a, t2.a, "
"(SELECT t1.a WHERE t1.a = t2.a) AS anon_1 FROM t1, t2")
- def _assert_column_backwards_correlated(self, stmt):
- self.assert_compile(stmt,
- "SELECT t2.a, (SELECT t1.a FROM t2 WHERE t1.a = t2.a) "
- "AS anon_1 FROM t2")
def _assert_having_correlated(self, stmt):
self.assert_compile(stmt,
def test_correlate_except_exclusion_where(self):
t1, t2, s1 = self._fixture()
- self._assert_where_backwards_correlated(
+ self._assert_where_uncorrelated(
select([t2]).where(t2.c.a == s1.correlate_except(t2)))
def test_correlate_except_inclusion_column(self):
def test_correlate_except_exclusion_column(self):
t1, t2, s1 = self._fixture()
- self._assert_column_backwards_correlated(
+ self._assert_column_uncorrelated(
select([t2, s1.correlate_except(t2).as_scalar()]))
def test_correlate_except_inclusion_from(self):
self._assert_from_uncorrelated(
select([t2, s1.correlate_except(t2).alias()]))
+ def test_correlate_except_none(self):
+ t1, t2, s1 = self._fixture()
+ self._assert_where_all_correlated(
+ select([t1, t2]).where(t2.c.a == s1.correlate_except(None)))
+
def test_correlate_except_having(self):
t1, t2, s1 = self._fixture()
self._assert_having_correlated(
self.assert_compile(s1.correlate(t1, t2),
"SELECT t1.a FROM t1, t2 WHERE t1.a = t2.a")
+ def test_correlate_except_froms(self):
+ # new as of #2748
+ t1 = table('t1', column('a'))
+ t2 = table('t2', column('a'), column('b'))
+ s = select([t2.c.b]).where(t1.c.a == t2.c.a)
+ s = s.correlate_except(t2).alias('s')
+
+ s2 = select([func.foo(s.c.b)]).as_scalar()
+ s3 = select([t1], order_by=s2)
+
+ self.assert_compile(s3,
+ "SELECT t1.a FROM t1 ORDER BY "
+ "(SELECT foo(s.b) AS foo_1 FROM "
+ "(SELECT t2.b AS b FROM t2 WHERE t1.a = t2.a) AS s)"
+ )
+
+ def test_multilevel_froms_correlation(self):
+ # new as of #2748
+ p = table('parent', column('id'))
+ c = table('child', column('id'), column('parent_id'), column('pos'))
+
+ s = c.select().where(c.c.parent_id == p.c.id).order_by(c.c.pos).limit(1)
+ s = s.correlate(p)
+ s = exists().select_from(s).where(s.c.id == 1)
+ s = select([p]).where(s)
+ self.assert_compile(s,
+ "SELECT parent.id FROM parent WHERE EXISTS (SELECT * "
+ "FROM (SELECT child.id AS id, child.parent_id AS parent_id, "
+ "child.pos AS pos FROM child WHERE child.parent_id = parent.id "
+ "ORDER BY child.pos LIMIT :param_1) WHERE id = :id_1)")
+
+ def test_no_contextless_correlate_except(self):
+ # new as of #2748
+
+ t1 = table('t1', column('x'))
+ t2 = table('t2', column('y'))
+ t3 = table('t3', column('z'))
+
+ s = select([t1]).where(t1.c.x == t2.c.y).\
+ where(t2.c.y == t3.c.z).correlate_except(t1)
+ self.assert_compile(s,
+ "SELECT t1.x FROM t1, t2, t3 WHERE t1.x = t2.y AND t2.y = t3.z")
+
+ def test_multilevel_implicit_correlation_disabled(self):
+ # test that implicit correlation with multilevel WHERE correlation
+ # behaves like 0.8.1, 0.7 (i.e. doesn't happen)
+ t1 = table('t1', column('x'))
+ t2 = table('t2', column('y'))
+ t3 = table('t3', column('z'))
+
+ s = select([t1.c.x]).where(t1.c.x == t2.c.y)
+ s2 = select([t3.c.z]).where(t3.c.z == s.as_scalar())
+ s3 = select([t1]).where(t1.c.x == s2.as_scalar())
+
+ self.assert_compile(s3,
+ "SELECT t1.x FROM t1 "
+ "WHERE t1.x = (SELECT t3.z "
+ "FROM t3 "
+ "WHERE t3.z = (SELECT t1.x "
+ "FROM t1, t2 "
+ "WHERE t1.x = t2.y))"
+ )
+
+ def test_from_implicit_correlation_disabled(self):
+ # test that implicit correlation with immediate and
+ # multilevel FROM clauses behaves like 0.8.1 (i.e. doesn't happen)
+ t1 = table('t1', column('x'))
+ t2 = table('t2', column('y'))
+ t3 = table('t3', column('z'))
+
+ s = select([t1.c.x]).where(t1.c.x == t2.c.y)
+ s2 = select([t2, s])
+ s3 = select([t1, s2])
+
+ self.assert_compile(s3,
+ "SELECT t1.x, y, x FROM t1, "
+ "(SELECT t2.y AS y, x FROM t2, "
+ "(SELECT t1.x AS x FROM t1, t2 WHERE t1.x = t2.y))"
+ )
+
class CoercionTest(fixtures.TestBase, AssertsCompiledSQL):
__dialect__ = 'default'
from sqlalchemy.testing import fixtures, AssertsCompiledSQL, \
AssertsExecutionResults
from sqlalchemy import testing
-from sqlalchemy.sql import util as sql_util, visitors
+from sqlalchemy.sql import util as sql_util, visitors, expression
from sqlalchemy import exc
from sqlalchemy.sql import table, column, null
from sqlalchemy import util
s = select([t])._clone()
assert c in s.c.bar.proxy_set
+ def test_cloned_intersection(self):
+ t1 = table('t1', column('x'))
+ t2 = table('t2', column('x'))
+
+ s1 = t1.select()
+ s2 = t2.select()
+ s3 = t1.select()
+
+ s1c1 = s1._clone()
+ s1c2 = s1._clone()
+ s2c1 = s2._clone()
+ s3c1 = s3._clone()
+
+ eq_(
+ expression._cloned_intersection(
+ [s1c1, s3c1], [s2c1, s1c2]
+ ),
+ set([s1c1])
+ )
+
+ def test_cloned_difference(self):
+ t1 = table('t1', column('x'))
+ t2 = table('t2', column('x'))
+
+ s1 = t1.select()
+ s2 = t2.select()
+ s3 = t1.select()
+
+ s1c1 = s1._clone()
+ s1c2 = s1._clone()
+ s2c1 = s2._clone()
+ s2c2 = s2._clone()
+ s3c1 = s3._clone()
+
+ eq_(
+ expression._cloned_difference(
+ [s1c1, s2c1, s3c1], [s2c1, s1c2]
+ ),
+ set([s3c1])
+ )
+
+
def test_distance_on_aliases(self):
a1 = table1.alias('a1')
for s in (select([a1, table1], use_labels=True),