.. changelog::
:version: 1.1.0b1
+ .. change::
+ :tags: feature, sql
+ :tickets: 2857
+
+ Added :meth:`.Select.lateral` and related constructs to allow
+ for the SQL standard LATERAL keyword, currently only supported
+ by Postgresql.
+
+ .. seealso::
+
+ :ref:`change_2857`
+
.. change::
:tags: feature, sql
:tickets: 1957
:ticket:`2551`
+.. _change_2857:
+
+Support for the SQL LATERAL keyword
+------------------------------------
+
+The LATERAL keyword is currently known to only be supported by Postgresql 9.3
+and greater, however as it is part of the SQL standard support for this keyword
+is added to Core. The implementation of :meth:`.Select.lateral` employs
+special logic beyond just rendering the LATERAL keyword to allow for
+correlation of tables that are derived from the same FROM clause as the
+selectable, e.g. lateral correlation::
+
+ >>> from sqlalchemy import table, column, select, true
+ >>> people = table('people', column('people_id'), column('age'), column('name'))
+ >>> books = table('books', column('book_id'), column('owner_id'))
+ >>> subq = select([books.c.book_id]).\
+ ... where(books.c.owner_id == people.c.people_id).lateral("book_subq")
+ >>> print (select([people]).select_from(people.join(subq, true())))
+ SELECT people.people_id, people.age, people.name
+ FROM people JOIN LATERAL (SELECT books.book_id AS book_id
+ FROM books WHERE books.owner_id = people.people_id)
+ AS book_subq ON true
+
+.. seealso::
+
+ :ref:`lateral_selects`
+
+ :class:`.Lateral`
+
+ :meth:`.Select.lateral`
+
+
+:ticket:`2857`
+
.. _change_3216:
The ``.autoincrement`` directive is no longer implicitly enabled for a composite primary key column
.. autofunction:: join
+.. autofunction:: lateral
+
.. autofunction:: outerjoin
.. autofunction:: select
:members:
:inherited-members:
+.. autoclass:: Lateral
+
.. autoclass:: ScalarSelect
:members:
('jack',)
{stop}[(u'jack', u'jack@yahoo.com'), (u'jack', u'jack@msn.com')]
+.. _lateral_selects:
+
+LATERAL correlation
+^^^^^^^^^^^^^^^^^^^
+
+LATERAL correlation is a special sub-category of SQL correlation which
+allows a selectable unit to refer to another selectable unit within a
+single FROM clause. This is an extremely special use case which, while
+part of the SQL standard, is only known to be supported by recent
+versions of Postgresql.
+
+Normally, if a SELECT statement refers to
+``table1 JOIN (some SELECT) AS subquery`` in its FROM clause, the subquery
+on the right side may not refer to the "table1" expression from the left side;
+correlation may only refer to a table that is part of another SELECT that
+entirely encloses this SELECT. The LATERAL keyword allows us to turn this
+behavior around, allowing an expression such as:
+
+.. sourcecode:: sql
+
+ SELECT people.people_id, people.age, people.name
+ FROM people JOIN LATERAL (SELECT books.book_id AS book_id
+ FROM books WHERE books.owner_id = people.people_id)
+ AS book_subq ON true
+
+Where above, the right side of the JOIN contains a subquery that refers not
+just to the "books" table but also the "people" table, correlating
+to the left side of the JOIN. SQLAlchemy Core supports a statement
+like the above using the :meth:`.Select.lateral` method as follows::
+
+ >>> from sqlalchemy import table, column, select, true
+ >>> people = table('people', column('people_id'), column('age'), column('name'))
+ >>> books = table('books', column('book_id'), column('owner_id'))
+ >>> subq = select([books.c.book_id]).\
+ ... where(books.c.owner_id == people.c.people_id).lateral("book_subq")
+ >>> print (select([people]).select_from(people.join(subq, true())))
+ SELECT people.people_id, people.age, people.name
+ FROM people JOIN LATERAL (SELECT books.book_id AS book_id
+ FROM books WHERE books.owner_id = people.people_id)
+ AS book_subq ON true
+
+Above, we can see that the :meth:`.Select.lateral` method acts a lot like
+the :meth:`.Select.alias` method, including that we can specify an optional
+name. However the construct is the :class:`.Lateral` construct instead of
+an :class:`.Alias` which provides for the LATERAL keyword as well as special
+instructions to allow correlation from inside the FROM clause of the
+enclosing statement.
+
+The :meth:`.Select.lateral` method interacts normally with the
+:meth:`.Select.correlate` and :meth:`.Select.correlate_except` methods, except
+that the correlation rules also apply to any other tables present in the
+enclosing statement's FROM clause. Correlation is "automatic" to these
+tables by default, is explicit if the table is specified to
+:meth:`.Select.correlate`, and is explicit to all tables except those
+specified to :meth:`.Select.correlate_except`.
+
+
+.. versionadded:: 1.1
+
+ Support for the LATERAL keyword and lateral correlation.
+
+.. seealso::
+
+ :class:`.Lateral`
+
+ :meth:`.Select.lateral`
+
+
Ordering, Grouping, Limiting, Offset...ing...
---------------------------------------------
intersect,
intersect_all,
join,
+ lateral,
literal,
literal_column,
modifier,
# DELETE FROM ONLY ...
table.delete().with_hint('ONLY', dialect_name='postgresql')
+
.. _postgresql_indexes:
Postgresql-Specific Index Options
intersect_all,
join,
label,
+ lateral,
literal,
literal_column,
modifier,
else:
return alias.original._compiler_dispatch(self, **kwargs)
+ def visit_lateral(self, lateral, **kw):
+ kw['lateral'] = True
+ return "LATERAL %s" % self.visit_alias(lateral, **kw)
+
def get_render_as_alias_suffix(self, alias_name_text):
return " AS " + alias_name_text
('asfrom_froms', frozenset())
])
- def _display_froms_for_select(self, select, asfrom):
+ def _display_froms_for_select(self, select, asfrom, lateral=False):
# utility method to help external dialects
# get the correct from list for a select.
# specifically the oracle dialect needs this feature
correlate_froms = entry['correlate_froms']
asfrom_froms = entry['asfrom_froms']
- if asfrom:
+ if asfrom and not lateral:
froms = select._get_display_froms(
explicit_correlate_froms=correlate_froms.difference(
asfrom_froms),
compound_index=0,
nested_join_translation=False,
select_wraps_for=None,
+ lateral=False,
**kwargs):
needs_nested_translation = \
select, transformed_select)
return text
- froms = self._setup_select_stack(select, entry, asfrom)
+ froms = self._setup_select_stack(select, entry, asfrom, lateral)
column_clause_args = kwargs.copy()
column_clause_args.update({
self.stack.pop(-1)
- if asfrom and parens:
+ if (asfrom or lateral) and parens:
return "(" + text + ")"
else:
return text
hint_text = self.get_select_hint_text(byfrom)
return hint_text, byfrom
- def _setup_select_stack(self, select, entry, asfrom):
+ def _setup_select_stack(self, select, entry, asfrom, lateral):
correlate_froms = entry['correlate_froms']
asfrom_froms = entry['asfrom_froms']
- if asfrom:
+ if asfrom and not lateral:
froms = select._get_display_froms(
explicit_correlate_froms=correlate_froms.difference(
asfrom_froms),
'selectable': select,
}
self.stack.append(new_entry)
+
return froms
def _compose_select_body(
__all__ = [
'Alias', 'Any', 'All', 'ClauseElement', 'ColumnCollection', 'ColumnElement',
- 'CompoundSelect', 'Delete', 'FromClause', 'Insert', 'Join', 'Select',
+ 'CompoundSelect', 'Delete', 'FromClause', 'Insert', 'Join', 'Lateral',
+ 'Select',
'Selectable', 'TableClause', 'Update', 'alias', 'and_', 'asc', 'between',
'bindparam', 'case', 'cast', 'column', 'delete', 'desc', 'distinct',
'except_', 'except_all', 'exists', 'extract', 'func', 'modifier',
'collate', 'insert', 'intersect', 'intersect_all', 'join', 'label',
- 'literal', 'literal_column', 'not_', 'null', 'nullsfirst', 'nullslast',
+ 'lateral', 'literal', 'literal_column', 'not_', 'null', 'nullsfirst',
+ 'nullslast',
'or_', 'outparam', 'outerjoin', 'over', 'select', 'subquery',
'table', 'text',
'tuple_', 'type_coerce', 'union', 'union_all', 'update', 'within_group']
PARSE_AUTOCOMMIT
from .selectable import Alias, Join, Select, Selectable, TableClause, \
- CompoundSelect, CTE, FromClause, FromGrouping, SelectBase, \
+ CompoundSelect, CTE, FromClause, FromGrouping, Lateral, SelectBase, \
alias, GenerativeSelect, subquery, HasCTE, HasPrefixes, HasSuffixes, \
- Exists, ScalarSelect, TextAsFrom
+ lateral, Exists, ScalarSelect, TextAsFrom
from .dml import Insert, Update, Delete, UpdateBase, ValuesBase
return selectable.alias(name=name, flat=flat)
+def lateral(selectable, name=None):
+ """Return a :class:`.Lateral` object.
+
+ :class:`.Lateral` is an :class:`.Alias` subclass that represents
+ a subquery with the LATERAL keyword applied to it.
+
+ The special behavior of a LATERAL subquery is that it appears in the
+ FROM clause of an enclosing SELECT, but may correlate to other
+ FROM clauses of that SELECT. It is a special case of subquery
+ only supported by a small number of backends, currently more recent
+ Postgresql versions.
+
+ .. versionadded:: 1.1
+
+ .. seealso::
+
+ :ref:`lateral_selects` - overview of usage.
+
+ """
+ return selectable.lateral(name=name)
+
+
class Selectable(ClauseElement):
"""mark a class as being selectable"""
__visit_name__ = 'selectable'
return Alias(self, name)
+ def lateral(self, name=None):
+ """Return a LATERAL alias of this :class:`.FromClause`.
+
+ The return value is the :class:`.Lateral` construct also
+ provided by the top-level :func:`~.expression.lateral` function.
+
+ .. versionadded:: 1.1
+
+ .. seealso::
+
+ :ref:`lateral_selects` - overview of usage.
+
+ """
+ return Lateral(self, name)
+
def is_derived_from(self, fromclause):
"""Return True if this FromClause is 'derived' from the given
FromClause.
return self.element.bind
+class Lateral(Alias):
+ """Represent a LATERAL subquery.
+
+ This object is constructed from the :func:`~.expression.lateral` module
+ level function as well as the :meth:`.FromClause.lateral` method available
+ on all :class:`.FromClause` subclasses.
+
+ While LATERAL is part of the SQL standard, curently only more recent
+ Postgresql versions provide support for this keyword.
+
+ .. versionadded:: 1.1
+
+ .. seealso::
+
+ :ref:`lateral_selects` - overview of usage.
+
+ """
+
+ __visit_name__ = 'lateral'
+
+
class CTE(Generative, HasSuffixes, Alias):
"""Represent a Common Table Expression.
--- /dev/null
+from sqlalchemy.testing import fixtures
+from sqlalchemy.testing import AssertsCompiledSQL, assert_raises_message
+from sqlalchemy.sql import select, func
+from sqlalchemy.engine import default
+from sqlalchemy import exc
+from sqlalchemy import Table, Integer, String, ForeignKey, Column, true
+from sqlalchemy import lateral, outerjoin, join
+
+
+class LateralTest(fixtures.TablesTest, AssertsCompiledSQL):
+ __dialect__ = default.DefaultDialect(supports_native_boolean=True)
+
+ run_setup_bind = None
+
+ run_create_tables = None
+
+ @classmethod
+ def define_tables(cls, metadata):
+ Table('people', metadata,
+ Column('people_id', Integer, primary_key=True),
+ Column('age', Integer),
+ Column('name', String(30)))
+ Table('bookcases', metadata,
+ Column('bookcase_id', Integer, primary_key=True),
+ Column(
+ 'bookcase_owner_id',
+ Integer, ForeignKey('people.people_id')),
+ Column('bookcase_shelves', Integer),
+ Column('bookcase_width', Integer))
+ Table('books', metadata,
+ Column('book_id', Integer, primary_key=True),
+ Column(
+ 'bookcase_id', Integer, ForeignKey('bookcases.bookcase_id')),
+ Column('book_owner_id', Integer, ForeignKey('people.people_id')),
+ Column('book_weight', Integer))
+
+ def test_standalone(self):
+ table1 = self.tables.people
+ subq = select([table1.c.people_id])
+
+ # alias name is not rendered because subquery is not
+ # in the context of a FROM clause
+ self.assert_compile(
+ lateral(subq, name="alias"),
+ 'LATERAL (SELECT people.people_id FROM people)'
+ )
+
+ self.assert_compile(
+ subq.lateral(name="alias"),
+ 'LATERAL (SELECT people.people_id FROM people)'
+ )
+
+ def test_select_from(self):
+ table1 = self.tables.people
+ subq = select([table1.c.people_id])
+
+ # in a FROM context, now you get "AS alias" and column labeling
+ self.assert_compile(
+ select([subq.lateral(name='alias')]),
+ 'SELECT alias.people_id FROM LATERAL '
+ '(SELECT people.people_id AS people_id FROM people) AS alias'
+ )
+
+ def test_plain_join(self):
+ table1 = self.tables.people
+ table2 = self.tables.books
+ subq = select([table2.c.book_id]).\
+ where(table2.c.book_owner_id == table1.c.people_id)
+
+ # FROM books, people? isn't this wrong? No! Because
+ # this is only a fragment, books isn't in any other FROM clause
+ self.assert_compile(
+ join(table1, lateral(subq, name="alias"), true()),
+ "people JOIN LATERAL (SELECT books.book_id AS book_id "
+ "FROM books, people WHERE books.book_owner_id = people.people_id) "
+ "AS alias ON true"
+ )
+
+ # put it in correct context, implicit correlation works fine
+ self.assert_compile(
+ select([table1]).select_from(
+ join(table1, lateral(subq, name="alias"), true())
+ ),
+ "SELECT people.people_id, people.age, people.name "
+ "FROM people JOIN LATERAL (SELECT books.book_id AS book_id "
+ "FROM books WHERE books.book_owner_id = people.people_id) "
+ "AS alias ON true"
+ )
+
+ # explicit correlation
+ subq = subq.correlate(table1)
+ self.assert_compile(
+ select([table1]).select_from(
+ join(table1, lateral(subq, name="alias"), true())
+ ),
+ "SELECT people.people_id, people.age, people.name "
+ "FROM people JOIN LATERAL (SELECT books.book_id AS book_id "
+ "FROM books WHERE books.book_owner_id = people.people_id) "
+ "AS alias ON true"
+ )
+
+ def test_join_lateral_w_select_subquery(self):
+ table1 = self.tables.people
+ table2 = self.tables.books
+
+ subq = select([table2.c.book_id]).\
+ correlate(table1).\
+ where(table1.c.people_id == table2.c.book_owner_id).lateral()
+ stmt = select([table1, subq.c.book_id]).\
+ select_from(table1.join(subq, true()))
+
+ self.assert_compile(
+ stmt,
+ "SELECT people.people_id, people.age, people.name, anon_1.book_id "
+ "FROM people JOIN LATERAL (SELECT books.book_id AS book_id "
+ "FROM books "
+ "WHERE people.people_id = books.book_owner_id) AS anon_1 ON true"
+ )
+
+ def test_from_function(self):
+ bookcases = self.tables.bookcases
+ srf = lateral(func.generate_series(1, bookcases.c.bookcase_shelves))
+
+ self.assert_compile(
+ select([bookcases]).select_from(bookcases.join(srf, true())),
+ "SELECT bookcases.bookcase_id, bookcases.bookcase_owner_id, "
+ "bookcases.bookcase_shelves, bookcases.bookcase_width "
+ "FROM bookcases JOIN "
+ "LATERAL generate_series(:generate_series_1, "
+ "bookcases.bookcase_shelves) AS anon_1 ON true"
+ )
+
+
+