_suffixes=self._suffixes,
)
- def union(self, other):
+ def union(self, *other):
+ r"""Return a new :class:`_expression.CTE` with a SQL ``UNION``
+ of the original CTE against the given selectables provided
+ as positional arguments.
+
+ :param \*other: one or more elements with which to create a
+ UNION.
+
+ .. versionchanged:: 1.4.28 multiple elements are now accepted.
+
+ .. seealso::
+
+ :meth:`_sql.HasCTE.cte` - examples of calling styles
+
+ """
return CTE._construct(
- self.element.union(other),
+ self.element.union(*other),
name=self.name,
recursive=self.recursive,
nesting=self.nesting,
_suffixes=self._suffixes,
)
- def union_all(self, other):
+ def union_all(self, *other):
+ r"""Return a new :class:`_expression.CTE` with a SQL ``UNION ALL``
+ of the original CTE against the given selectables provided
+ as positional arguments.
+
+ :param \*other: one or more elements with which to create a
+ UNION.
+
+ .. versionchanged:: 1.4.28 multiple elements are now accepted.
+
+ .. seealso::
+
+ :meth:`_sql.HasCTE.cte` - examples of calling styles
+
+ """
return CTE._construct(
- self.element.union_all(other),
+ self.element.union_all(*other),
name=self.name,
recursive=self.recursive,
nesting=self.nesting,
connection.execute(upsert)
- Example 4, Nesting CTE::
+ Example 4, Nesting CTE (SQLAlchemy 1.4.24 and above)::
value_a = select(
literal("root").label("n")
SELECT value_a.n AS a, value_b.n AS b
FROM value_a, value_b
+ Example 5, Non-Linear CTE (SQLAlchemy 1.4.28 and above)::
+
+ edge = Table(
+ "edge",
+ metadata,
+ Column("id", Integer, primary_key=True),
+ Column("left", Integer),
+ Column("right", Integer),
+ )
+
+ root_node = select(literal(1).label("node")).cte(
+ "nodes", recursive=True
+ )
+
+ left_edge = select(edge.c.left).join(
+ root_node, edge.c.right == root_node.c.node
+ )
+ right_edge = select(edge.c.right).join(
+ root_node, edge.c.left == root_node.c.node
+ )
+
+ subgraph_cte = root_node.union(left_edge, right_edge)
+
+ subgraph = select(subgraph_cte)
+
+ The above query will render 2 UNIONs inside the recursive CTE::
+
+ WITH RECURSIVE nodes(node) AS (
+ SELECT 1 AS node
+ UNION
+ SELECT edge."left" AS "left"
+ FROM edge JOIN nodes ON edge."right" = nodes.node
+ UNION
+ SELECT edge."right" AS "right"
+ FROM edge JOIN nodes ON edge."left" = nodes.node
+ )
+ SELECT nodes.node FROM nodes
+
.. seealso::
:meth:`_orm.Query.cte` - ORM version of
else:
return SelectStatementGrouping(self)
- def union(self, other, **kwargs):
- """Return a SQL ``UNION`` of this select() construct against
- the given selectable.
+ def union(self, *other, **kwargs):
+ r"""Return a SQL ``UNION`` of this select() construct against
+ the given selectables provided as positional arguments.
+
+ :param \*other: one or more elements with which to create a
+ UNION.
+
+ .. versionchanged:: 1.4.28
+
+ multiple elements are now accepted.
+
+ :param \**kwargs: keyword arguments are forwarded to the constructor
+ for the newly created :class:`_sql.CompoundSelect` object.
"""
- return CompoundSelect._create_union(self, other, **kwargs)
+ return CompoundSelect._create_union(self, *other, **kwargs)
+
+ def union_all(self, *other, **kwargs):
+ r"""Return a SQL ``UNION ALL`` of this select() construct against
+ the given selectables provided as positional arguments.
+
+ :param \*other: one or more elements with which to create a
+ UNION.
- def union_all(self, other, **kwargs):
- """Return a SQL ``UNION ALL`` of this select() construct against
- the given selectable.
+ .. versionchanged:: 1.4.28
+
+ multiple elements are now accepted.
+
+ :param \**kwargs: keyword arguments are forwarded to the constructor
+ for the newly created :class:`_sql.CompoundSelect` object.
"""
- return CompoundSelect._create_union_all(self, other, **kwargs)
+ return CompoundSelect._create_union_all(self, *other, **kwargs)
+
+ def except_(self, *other, **kwargs):
+ r"""Return a SQL ``EXCEPT`` of this select() construct against
+ the given selectable provided as positional arguments.
+
+ :param \*other: one or more elements with which to create a
+ UNION.
+
+ .. versionchanged:: 1.4.28
+
+ multiple elements are now accepted.
- def except_(self, other, **kwargs):
- """Return a SQL ``EXCEPT`` of this select() construct against
- the given selectable.
+ :param \**kwargs: keyword arguments are forwarded to the constructor
+ for the newly created :class:`_sql.CompoundSelect` object.
"""
- return CompoundSelect._create_except(self, other, **kwargs)
+ return CompoundSelect._create_except(self, *other, **kwargs)
- def except_all(self, other, **kwargs):
- """Return a SQL ``EXCEPT ALL`` of this select() construct against
- the given selectable.
+ def except_all(self, *other, **kwargs):
+ r"""Return a SQL ``EXCEPT ALL`` of this select() construct against
+ the given selectables provided as positional arguments.
+
+ :param \*other: one or more elements with which to create a
+ UNION.
+
+ .. versionchanged:: 1.4.28
+
+ multiple elements are now accepted.
+
+ :param \**kwargs: keyword arguments are forwarded to the constructor
+ for the newly created :class:`_sql.CompoundSelect` object.
"""
- return CompoundSelect._create_except_all(self, other, **kwargs)
+ return CompoundSelect._create_except_all(self, *other, **kwargs)
+
+ def intersect(self, *other, **kwargs):
+ r"""Return a SQL ``INTERSECT`` of this select() construct against
+ the given selectables provided as positional arguments.
+
+ :param \*other: one or more elements with which to create a
+ UNION.
- def intersect(self, other, **kwargs):
- """Return a SQL ``INTERSECT`` of this select() construct against
- the given selectable.
+ .. versionchanged:: 1.4.28
+
+ multiple elements are now accepted.
+
+ :param \**kwargs: keyword arguments are forwarded to the constructor
+ for the newly created :class:`_sql.CompoundSelect` object.
"""
- return CompoundSelect._create_intersect(self, other, **kwargs)
+ return CompoundSelect._create_intersect(self, *other, **kwargs)
+
+ def intersect_all(self, *other, **kwargs):
+ r"""Return a SQL ``INTERSECT ALL`` of this select() construct
+ against the given selectables provided as positional arguments.
+
+ :param \*other: one or more elements with which to create a
+ UNION.
+
+ .. versionchanged:: 1.4.28
+
+ multiple elements are now accepted.
- def intersect_all(self, other, **kwargs):
- """Return a SQL ``INTERSECT ALL`` of this select() construct
- against the given selectable.
+ :param \**kwargs: keyword arguments are forwarded to the constructor
+ for the newly created :class:`_sql.CompoundSelect` object.
"""
- return CompoundSelect._create_intersect_all(self, other, **kwargs)
+ return CompoundSelect._create_intersect_all(self, *other, **kwargs)
@property
@util.deprecated_20(
"foo",
)
+ def test_recursive_cte_with_multiple_union(self):
+ root_query = select(literal(1).label("val")).cte(
+ "increasing", recursive=True
+ )
+ rec_part_1 = select((root_query.c.val + 3).label("val")).where(
+ root_query.c.val < 15
+ )
+ rec_part_2 = select((root_query.c.val + 5).label("val")).where(
+ root_query.c.val < 15
+ )
+ union_rec_query = root_query.union(rec_part_1, rec_part_2)
+ union_stmt = select(union_rec_query)
+ self.assert_compile(
+ union_stmt,
+ "WITH RECURSIVE increasing(val) AS "
+ "(SELECT :param_1 AS val "
+ "UNION SELECT increasing.val + :val_1 AS val FROM increasing "
+ "WHERE increasing.val < :val_2 "
+ "UNION SELECT increasing.val + :val_3 AS val FROM increasing "
+ "WHERE increasing.val < :val_4) "
+ "SELECT increasing.val FROM increasing",
+ )
+
+ def test_recursive_cte_with_multiple_union_all(self):
+ root_query = select(literal(1).label("val")).cte(
+ "increasing", recursive=True
+ )
+ rec_part_1 = select((root_query.c.val + 3).label("val")).where(
+ root_query.c.val < 15
+ )
+ rec_part_2 = select((root_query.c.val + 5).label("val")).where(
+ root_query.c.val < 15
+ )
+
+ union_all_rec_query = root_query.union_all(rec_part_1, rec_part_2)
+ union_all_stmt = select(union_all_rec_query)
+ self.assert_compile(
+ union_all_stmt,
+ "WITH RECURSIVE increasing(val) AS "
+ "(SELECT :param_1 AS val "
+ "UNION ALL SELECT increasing.val + :val_1 AS val FROM increasing "
+ "WHERE increasing.val < :val_2 "
+ "UNION ALL SELECT increasing.val + :val_3 AS val FROM increasing "
+ "WHERE increasing.val < :val_4) "
+ "SELECT increasing.val FROM increasing",
+ )
+
class NestingCTETest(fixtures.TestBase, AssertsCompiledSQL):
from sqlalchemy import select
from sqlalchemy import String
from sqlalchemy import Table
+from sqlalchemy import testing
from sqlalchemy import tuple_
from sqlalchemy import union
from sqlalchemy.sql import column
+from sqlalchemy.sql import literal
from sqlalchemy.sql import table
from sqlalchemy.testing import assert_raises_message
from sqlalchemy.testing import AssertsCompiledSQL
from sqlalchemy.testing import fixtures
-
table1 = table(
"mytable",
column("myid", Integer),
"SELECT anon_1.name FROM (SELECT mytable.name AS name, "
"(mytable.myid, mytable.name) AS anon_2 FROM mytable) AS anon_1",
)
+
+ @testing.combinations(
+ ("union_all", "UNION ALL"),
+ ("union", "UNION"),
+ ("intersect_all", "INTERSECT ALL"),
+ ("intersect", "INTERSECT"),
+ ("except_all", "EXCEPT ALL"),
+ ("except_", "EXCEPT"),
+ )
+ def test_select_multiple_compound_elements(self, methname, joiner):
+ stmt = select(literal(1))
+ meth = getattr(stmt, methname)
+ stmt = meth(select(literal(2)), select(literal(3)))
+
+ self.assert_compile(
+ stmt,
+ "SELECT :param_1 AS anon_1"
+ " %(joiner)s SELECT :param_2 AS anon_2"
+ " %(joiner)s SELECT :param_3 AS anon_3" % {"joiner": joiner},
+ )