>>> from sqlalchemy import select
>>> stmt = select(user_table).where(user_table.c.name == "spongebob")
>>> print(stmt)
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account
WHERE user_account.name = :name_1
Also in the same manner as all other statement-level SQL constructs, to
actually run the statement we pass it to an execution method.
Since a SELECT statement returns
rows we can always iterate the result object to get Row
objects back:
>>> with engine.connect() as conn:
... for row in conn.execute(stmt):
... print(row)
BEGIN (implicit)
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account
WHERE user_account.name = ?
[...] ('spongebob',)
(1, 'spongebob', 'Spongebob Squarepants')
ROLLBACK
When using the ORM, particularly with a select()
construct that’s
composed against ORM entities, we will want to execute it using the
Session.execute()
method on the Session
; using
this approach, we continue to get Row
objects from the
result, however these rows are now capable of including
complete entities, such as instances of the User
class, as individual
elements within each row:
>>> stmt = select(User).where(User.name == "spongebob")
>>> with Session(engine) as session:
... for row in session.execute(stmt):
... print(row)
BEGIN (implicit)
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account
WHERE user_account.name = ?
[...] ('spongebob',)
(User(id=1, name='spongebob', fullname='Spongebob Squarepants'),)
ROLLBACK
select() from a Table vs. ORM class
While the SQL generated in these examples looks the same whether we invoke
select(user_table)
or select(User)
, in the more general case
they do not necessarily render the same thing, as an ORM-mapped class
may be mapped to other kinds of “selectables” besides tables. The
select()
that’s against an ORM entity also indicates that ORM-mapped
instances should be returned in a result, which is not the case when
SELECTing from a Table
object.
The following sections will discuss the SELECT construct in more detail.
Setting the COLUMNS and FROM clause
The select()
function accepts positional elements representing any
number of Column
and/or Table
expressions, as
well as a wide range of compatible objects, which are resolved into a list of SQL
expressions to be SELECTed from that will be returned as columns in the result
set. These elements also serve in simpler cases to create the FROM clause,
which is inferred from the columns and table-like expressions passed:
>>> print(select(user_table))
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account
To SELECT from individual columns using a Core approach,
Column
objects are accessed from the Table.c
accessor and can be sent directly; the FROM clause will be inferred as the set
of all Table
and other FromClause
objects that
are represented by those columns:
>>> print(select(user_table.c.name, user_table.c.fullname))
SELECT user_account.name, user_account.fullname
FROM user_account
Alternatively, when using the FromClause.c
collection of any
FromClause
such as Table
, multiple columns may be specified
for a select()
by using a tuple of string names:
>>> print(select(user_table.c["name", "fullname"]))
SELECT user_account.name, user_account.fullname
FROM user_account
New in version 2.0: Added tuple-accessor capability to the
FromClause.c
collection
Selecting ORM Entities and Columns
ORM entities, such our User
class as well as the column-mapped
attributes upon it such as User.name
, also participate in the SQL Expression
Language system representing tables and columns. Below illustrates an
example of SELECTing from the User
entity, which ultimately renders
in the same way as if we had used user_table
directly:
>>> print(select(User))
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account
When executing a statement like the above using the ORM Session.execute()
method, there is an important difference when we select from a full entity
such as User
, as opposed to user_table
, which is that the entity
itself is returned as a single element within each row. That is, when we fetch rows from
the above statement, as there is only the User
entity in the list of
things to fetch, we get back Row
objects that have only one element, which contain
instances of the User
class:
>>> row = session.execute(select(User)).first()
BEGIN...
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account
[...] ()
(User(id=1, name='spongebob', fullname='Spongebob Squarepants'),)
The above Row
has just one element, representing the User
entity:
>>> row[0]
User(id=1, name='spongebob', fullname='Spongebob Squarepants')
A highly recommended convenience method of achieving the same result as above
is to use the Session.scalars()
method to execute the statement
directly; this method will return a ScalarResult
object
that delivers the first “column” of each row at once, in this case,
instances of the User
class:
>>> user = session.scalars(select(User)).first()
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account
[...] ()
User(id=1, name='spongebob', fullname='Spongebob Squarepants')
Alternatively, we can select individual columns of an ORM entity as distinct
elements within result rows, by using the class-bound attributes; when these
are passed to a construct such as select()
, they are resolved into
the Column
or other SQL expression represented by each
attribute:
>>> print(select(User.name, User.fullname))
SELECT user_account.name, user_account.fullname
FROM user_account
When we invoke this statement using Session.execute()
, we now
receive rows that have individual elements per value, each corresponding
to a separate column or other SQL expression:
>>> row = session.execute(select(User.name, User.fullname)).first()
SELECT user_account.name, user_account.fullname
FROM user_account
[...] ()
('spongebob', 'Spongebob Squarepants')
The approaches can also be mixed, as below where we SELECT the name
attribute of the User
entity as the first element of the row, and combine
it with full Address
entities in the second element:
>>> session.execute(
... select(User.name, Address).where(User.id == Address.user_id).order_by(Address.id)
... ).all()
SELECT user_account.name, address.id, address.email_address, address.user_id
FROM user_account, address
WHERE user_account.id = address.user_id ORDER BY address.id
[...] ()
[('spongebob', Address(id=1, email_address='[email protected]')),
('sandy', Address(id=2, email_address='[email protected]')),
('sandy', Address(id=3, email_address='[email protected]'))]
Approaches towards selecting ORM entities and columns as well as common methods
for converting rows are discussed further at Selecting ORM Entities and Attributes.
See also
Selecting ORM Entities and Attributes - in the ORM Querying Guide
Selecting from Labeled SQL Expressions
The ColumnElement.label()
method as well as the same-named method
available on ORM attributes provides a SQL label of a column or expression,
allowing it to have a specific name in a result set. This can be helpful
when referring to arbitrary SQL expressions in a result row by name:
>>> from sqlalchemy import func, cast
>>> stmt = select(
... ("Username: " + user_table.c.name).label("username"),
... ).order_by(user_table.c.name)
>>> with engine.connect() as conn:
... for row in conn.execute(stmt):
... print(f"{row.username}")
BEGIN (implicit)
SELECT ? || user_account.name AS username
FROM user_account ORDER BY user_account.name
[...] ('Username: ',)
Username: patrick
Username: sandy
Username: spongebob
ROLLBACK
See also
Ordering or Grouping by a Label - the label names we create may also be
referenced in the ORDER BY or GROUP BY clause of the Select
.
Selecting with Textual Column Expressions
When we construct a Select
object using the select()
function, we are normally passing to it a series of Table
and Column
objects that were defined using
table metadata, or when using the ORM we may be
sending ORM-mapped attributes that represent table columns. However,
sometimes there is also the need to manufacture arbitrary SQL blocks inside
of statements, such as constant string expressions, or just some arbitrary
SQL that’s quicker to write literally.
The text()
construct introduced at
Working with Transactions and the DBAPI can in fact be embedded into a
Select
construct directly, such as below where we manufacture
a hardcoded string literal 'some phrase'
and embed it within the
SELECT statement:
>>> from sqlalchemy import text
>>> stmt = select(text("'some phrase'"), user_table.c.name).order_by(user_table.c.name)
>>> with engine.connect() as conn:
... print(conn.execute(stmt).all())
BEGIN (implicit)
SELECT 'some phrase', user_account.name
FROM user_account ORDER BY user_account.name
[generated in ...] ()
[('some phrase', 'patrick'), ('some phrase', 'sandy'), ('some phrase', 'spongebob')]
ROLLBACK
While the text()
construct can be used in most places to inject
literal SQL phrases, more often than not we are actually dealing with textual
units that each represent an individual
column expression. In this common case we can get more functionality out of
our textual fragment using the literal_column()
construct instead. This object is similar to text()
except that
instead of representing arbitrary SQL of any form,
it explicitly represents a single “column” and can then be labeled and referred
towards in subqueries and other expressions:
>>> from sqlalchemy import literal_column
>>> stmt = select(literal_column("'some phrase'").label("p"), user_table.c.name).order_by(
... user_table.c.name
... )
>>> with engine.connect() as conn:
... for row in conn.execute(stmt):
... print(f"{row.p}, {row.name}")
BEGIN (implicit)
SELECT 'some phrase' AS p, user_account.name
FROM user_account ORDER BY user_account.name
[generated in ...] ()
some phrase, patrick
some phrase, sandy
some phrase, spongebob
ROLLBACK
Note that in both cases, when using text()
or
literal_column()
, we are writing a syntactical SQL expression, and
not a literal value. We therefore have to include whatever quoting or syntaxes
are necessary for the SQL we want to see rendered.
The WHERE clause
SQLAlchemy allows us to compose SQL expressions, such as name = 'squidward'
or user_id > 10
, by making use of standard Python operators in
conjunction with
Column
and similar objects. For boolean expressions, most
Python operators such as ==
, !=
, <
, >=
etc. generate new
SQL Expression objects, rather than plain boolean True
/False
values:
>>> print(user_table.c.name == "squidward")
user_account.name = :name_1
>>> print(address_table.c.user_id > 10)
address.user_id > :user_id_1
We can use expressions like these to generate the WHERE clause by passing
the resulting objects to the Select.where()
method:
>>> print(select(user_table).where(user_table.c.name == "squidward"))
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account
WHERE user_account.name = :name_1
To produce multiple expressions joined by AND, the Select.where()
method may be invoked any number of times:
>>> print(
... select(address_table.c.email_address)
... .where(user_table.c.name == "squidward")
... .where(address_table.c.user_id == user_table.c.id)
... )
SELECT address.email_address
FROM address, user_account
WHERE user_account.name = :name_1 AND address.user_id = user_account.id
A single call to Select.where()
also accepts multiple expressions
with the same effect:
>>> print(
... select(address_table.c.email_address).where(
... user_table.c.name == "squidward",
... address_table.c.user_id == user_table.c.id,
... )
... )
SELECT address.email_address
FROM address, user_account
WHERE user_account.name = :name_1 AND address.user_id = user_account.id
“AND” and “OR” conjunctions are both available directly using the
and_()
and or_()
functions, illustrated below in terms
of ORM entities:
>>> from sqlalchemy import and_, or_
>>> print(
... select(Address.email_address).where(
... and_(
... or_(User.name == "squidward", User.name == "sandy"),
... Address.user_id == User.id,
... )
... )
... )
SELECT address.email_address
FROM address, user_account
WHERE (user_account.name = :name_1 OR user_account.name = :name_2)
AND address.user_id = user_account.id
For simple “equality” comparisons against a single entity, there’s also a
popular method known as Select.filter_by()
which accepts keyword
arguments that match to column keys or ORM attribute names. It will filter
against the leftmost FROM clause or the last entity joined:
>>> print(select(User).filter_by(name="spongebob", fullname="Spongebob Squarepants"))
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account
WHERE user_account.name = :name_1 AND user_account.fullname = :fullname_1
See also
Operator Reference - descriptions of most SQL operator functions in SQLAlchemy
Explicit FROM clauses and JOINs
As mentioned previously, the FROM clause is usually inferred
based on the expressions that we are setting in the columns
clause as well as other elements of the Select
.
If we set a single column from a particular Table
in the COLUMNS clause, it puts that Table
in the FROM
clause as well:
>>> print(select(user_table.c.name))
SELECT user_account.name
FROM user_account
If we were to put columns from two tables, then we get a comma-separated FROM
clause:
>>> print(select(user_table.c.name, address_table.c.email_address))
SELECT user_account.name, address.email_address
FROM user_account, address
In order to JOIN these two tables together, we typically use one of two methods
on Select
. The first is the Select.join_from()
method, which allows us to indicate the left and right side of the JOIN
explicitly:
>>> print(
... select(user_table.c.name, address_table.c.email_address).join_from(
... user_table, address_table
... )
... )
SELECT user_account.name, address.email_address
FROM user_account JOIN address ON user_account.id = address.user_id
The other is the Select.join()
method, which indicates only the
right side of the JOIN, the left hand-side is inferred:
>>> print(select(user_table.c.name, address_table.c.email_address).join(address_table))
SELECT user_account.name, address.email_address
FROM user_account JOIN address ON user_account.id = address.user_id
When using Select.join_from()
or Select.join()
, we may
observe that the ON clause of the join is also inferred for us in simple
foreign key cases. More on that in the next section.
We also have the option to add elements to the FROM clause explicitly, if it is not
inferred the way we want from the columns clause. We use the
Select.select_from()
method to achieve this, as below
where we establish user_table
as the first element in the FROM
clause and Select.join()
to establish address_table
as
the second:
>>> print(select(address_table.c.email_address).select_from(user_table).join(address_table))
SELECT address.email_address
FROM user_account JOIN address ON user_account.id = address.user_id
Another example where we might want to use Select.select_from()
is if our columns clause doesn’t have enough information to provide for a
FROM clause. For example, to SELECT from the common SQL expression
count(*)
, we use a SQLAlchemy element known as sqlalchemy.sql.expression.func
to
produce the SQL count()
function:
>>> from sqlalchemy import func
>>> print(select(func.count("*")).select_from(user_table))
SELECT count(:count_2) AS count_1
FROM user_account
See also
Setting the leftmost FROM clause in a join - in the ORM Querying Guide -
contains additional examples and notes
regarding the interaction of Select.select_from()
and
Select.join()
.
Setting the ON Clause
The previous examples of JOIN illustrated that the Select
construct
can join between two tables and produce the ON clause automatically. This
occurs in those examples because the user_table
and address_table
Table
objects include a single ForeignKeyConstraint
definition which is used to form this ON clause.
If the left and right targets of the join do not have such a constraint, or
there are multiple constraints in place, we need to specify the ON clause
directly. Both Select.join()
and Select.join_from()
accept an additional argument for the ON clause, which is stated using the
same SQL Expression mechanics as we saw about in The WHERE clause:
>>> print(
... select(address_table.c.email_address)
... .select_from(user_table)
... .join(address_table, user_table.c.id == address_table.c.user_id)
... )
SELECT address.email_address
FROM user_account JOIN address ON user_account.id = address.user_id
ORM Tip - there’s another way to generate the ON clause when using
ORM entities that make use of the relationship()
construct,
like the mapping set up in the previous section at
Declaring Mapped Classes.
This is a whole subject onto itself, which is introduced at length
at Using Relationships to Join.
OUTER and FULL join
Both the Select.join()
and Select.join_from()
methods
accept keyword arguments Select.join.isouter
and
Select.join.full
which will render LEFT OUTER JOIN
and FULL OUTER JOIN, respectively:
>>> print(select(user_table).join(address_table, isouter=True))
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account LEFT OUTER JOIN address ON user_account.id = address.user_id
>>> print(select(user_table).join(address_table, full=True))
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account FULL OUTER JOIN address ON user_account.id = address.user_id
There is also a method Select.outerjoin()
that is equivalent to
using .join(..., isouter=True)
.
SQL also has a “RIGHT OUTER JOIN”. SQLAlchemy doesn’t render this directly;
instead, reverse the order of the tables and use “LEFT OUTER JOIN”.
ORDER BY, GROUP BY, HAVING
The SELECT SQL statement includes a clause called ORDER BY which is used to
return the selected rows within a given ordering.
The GROUP BY clause is constructed similarly to the ORDER BY clause, and has
the purpose of sub-dividing the selected rows into specific groups upon which
aggregate functions may be invoked. The HAVING clause is usually used with
GROUP BY and is of a similar form to the WHERE clause, except that it’s applied
to the aggregated functions used within groups.
ORDER BY
The ORDER BY clause is constructed in terms
of SQL Expression constructs typically based on Column
or
similar objects. The Select.order_by()
method accepts one or
more of these expressions positionally:
>>> print(select(user_table).order_by(user_table.c.name))
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account ORDER BY user_account.name
Ascending / descending is available from the ColumnElement.asc()
and ColumnElement.desc()
modifiers, which are present
from ORM-bound attributes as well:
>>> print(select(User).order_by(User.fullname.desc()))
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account ORDER BY user_account.fullname DESC
The above statement will yield rows that are sorted by the
user_account.fullname
column in descending order.
Aggregate functions with GROUP BY / HAVING
In SQL, aggregate functions allow column expressions across multiple rows
to be aggregated together to produce a single result. Examples include
counting, computing averages, as well as locating the maximum or minimum
value in a set of values.
SQLAlchemy provides for SQL functions in an open-ended way using a namespace
known as func
. This is a special constructor object which
will create new instances of Function
when given the name
of a particular SQL function, which can have any name, as well as zero or
more arguments to pass to the function, which are, like in all other cases,
SQL Expression constructs. For example, to
render the SQL COUNT() function against the user_account.id
column,
we call upon the count()
name:
>>> from sqlalchemy import func
>>> count_fn = func.count(user_table.c.id)
>>> print(count_fn)
count(user_account.id)
SQL functions are described in more detail later in this tutorial at
Working with SQL Functions.
When using aggregate functions in SQL, the GROUP BY clause is essential in that
it allows rows to be partitioned into groups where aggregate functions will
be applied to each group individually. When requesting non-aggregated columns
in the COLUMNS clause of a SELECT statement, SQL requires that these columns
all be subject to a GROUP BY clause, either directly or indirectly based on
a primary key association. The HAVING clause is then used in a similar
manner as the WHERE clause, except that it filters out rows based on aggregated
values rather than direct row contents.
SQLAlchemy provides for these two clauses using the Select.group_by()
and Select.having()
methods. Below we illustrate selecting
user name fields as well as count of addresses, for those users that have more
than one address:
>>> with engine.connect() as conn:
... result = conn.execute(
... select(User.name, func.count(Address.id).label("count"))
... .join(Address)
... .group_by(User.name)
... .having(func.count(Address.id) > 1)
... )
... print(result.all())
BEGIN (implicit)
SELECT user_account.name, count(address.id) AS count
FROM user_account JOIN address ON user_account.id = address.user_id GROUP BY user_account.name
HAVING count(address.id) > ?
[...] (1,)
[('sandy', 2)]
ROLLBACK
Ordering or Grouping by a Label
An important technique, in particular on some database backends, is the ability
to ORDER BY or GROUP BY an expression that is already stated in the columns
clause, without re-stating the expression in the ORDER BY or GROUP BY clause
and instead using the column name or labeled name from the COLUMNS clause.
This form is available by passing the string text of the name to the
Select.order_by()
or Select.group_by()
method. The text
passed is not rendered directly; instead, the name given to an expression
in the columns clause and rendered as that expression name in context, raising an
error if no match is found. The unary modifiers
asc()
and desc()
may also be used in this form:
>>> from sqlalchemy import func, desc
>>> stmt = (
... select(Address.user_id, func.count(Address.id).label("num_addresses"))
... .group_by("user_id")
... .order_by("user_id", desc("num_addresses"))
... )
>>> print(stmt)
SELECT address.user_id, count(address.id) AS num_addresses
FROM address GROUP BY address.user_id ORDER BY address.user_id, num_addresses DESC
Using Aliases
Now that we are selecting from multiple tables and using joins, we quickly
run into the case where we need to refer to the same table multiple times
in the FROM clause of a statement. We accomplish this using SQL aliases,
which are a syntax that supplies an alternative name to a table or subquery
from which it can be referenced in the statement.
In the SQLAlchemy Expression Language, these “names” are instead represented by
FromClause
objects known as the Alias
construct,
which is constructed in Core using the FromClause.alias()
method. An Alias
construct is just like a Table
construct in that it also has a namespace of Column
objects within the Alias.c
collection. The SELECT statement
below for example returns all unique pairs of user names:
>>> user_alias_1 = user_table.alias()
>>> user_alias_2 = user_table.alias()
>>> print(
... select(user_alias_1.c.name, user_alias_2.c.name).join_from(
... user_alias_1, user_alias_2, user_alias_1.c.id > user_alias_2.c.id
... )
... )
SELECT user_account_1.name, user_account_2.name AS name_1
FROM user_account AS user_account_1
JOIN user_account AS user_account_2 ON user_account_1.id > user_account_2.id
ORM Entity Aliases
The ORM equivalent of the FromClause.alias()
method is the
ORM aliased()
function, which may be applied to an entity
such as User
and Address
. This produces a Alias
object
internally that’s against the original mapped Table
object,
while maintaining ORM functionality. The SELECT below selects from the
User
entity all objects that include two particular email addresses:
>>> from sqlalchemy.orm import aliased
>>> address_alias_1 = aliased(Address)
>>> address_alias_2 = aliased(Address)
>>> print(
... select(User)
... .join_from(User, address_alias_1)
... .where(address_alias_1.email_address == "[email protected]")
... .join_from(User, address_alias_2)
... .where(address_alias_2.email_address == "[email protected]")
... )
SELECT user_account.id, user_account.name, user_account.fullname
FROM user_account
JOIN address AS address_1 ON user_account.id = address_1.user_id
JOIN address AS address_2 ON user_account.id = address_2.user_id
WHERE address_1.email_address = :email_address_1
AND address_2.email_address = :email_address_2
As mentioned in Setting the ON Clause, the ORM provides
for another way to join using the relationship()
construct.
The above example using aliases is demonstrated using relationship()
at Using Relationship to join between aliased targets.
Subqueries and CTEs
A subquery in SQL is a SELECT statement that is rendered within parenthesis and
placed within the context of an enclosing statement, typically a SELECT
statement but not necessarily.
This section will cover a so-called “non-scalar” subquery, which is typically
placed in the FROM clause of an enclosing SELECT. We will also cover the
Common Table Expression or CTE, which is used in a similar way as a subquery,
but includes additional features.
SQLAlchemy uses the Subquery
object to represent a subquery and
the CTE
to represent a CTE, usually obtained from the
Select.subquery()
and Select.cte()
methods, respectively.
Either object can be used as a FROM element inside of a larger
select()
construct.
We can construct a Subquery
that will select an aggregate count
of rows from the address
table (aggregate functions and GROUP BY were
introduced previously at Aggregate functions with GROUP BY / HAVING):
>>> subq = (
... select(func.count(address_table.c.id).label("count"), address_table.c.user_id)
... .group_by(address_table.c.user_id)
... .subquery()
... )
Stringifying the subquery by itself without it being embedded inside of another
Select
or other statement produces the plain SELECT statement
without any enclosing parenthesis:
>>> print(subq)
SELECT count(address.id) AS count, address.user_id
FROM address GROUP BY address.user_id
The Subquery
object behaves like any other FROM object such
as a Table
, notably that it includes a Subquery.c
namespace of the columns which it selects. We can use this namespace to
refer to both the user_id
column as well as our custom labeled
count
expression:
>>> print(select(subq.c.user_id, subq.c.count))
SELECT anon_1.user_id, anon_1.count
FROM (SELECT count(address.id) AS count, address.user_id AS user_id
FROM address GROUP BY address.user_id) AS anon_1
With a selection of rows contained within the subq
object, we can apply
the object to a larger Select
that will join the data to
the user_account
table:
>>> stmt = select(user_table.c.name, user_table.c.fullname, subq.c.count).join_from(
... user_table, subq
... )
>>> print(stmt)
SELECT user_account.name, user_account.fullname, anon_1.count
FROM user_account JOIN (SELECT count(address.id) AS count, address.user_id AS user_id
FROM address GROUP BY address.user_id) AS anon_1 ON user_account.id = anon_1.user_id
In order to join from user_account
to address
, we made use of the
Select.join_from()
method. As has been illustrated previously, the
ON clause of this join was again inferred based on foreign key constraints.
Even though a SQL subquery does not itself have any constraints, SQLAlchemy can
act upon constraints represented on the columns by determining that the
subq.c.user_id
column is derived from the address_table.c.user_id
column, which does express a foreign key relationship back to the
user_table.c.id
column which is then used to generate the ON clause.
Common Table Expressions (CTEs)
Usage of the CTE
construct in SQLAlchemy is virtually
the same as how the Subquery
construct is used. By changing
the invocation of the Select.subquery()
method to use
Select.cte()
instead, we can use the resulting object as a FROM
element in the same way, but the SQL rendered is the very different common
table expression syntax:
>>> subq = (
... select(func.count(address_table.c.id).label("count"), address_table.c.user_id)
... .group_by(address_table.c.user_id)
... .cte()
... )
>>> stmt = select(user_table.c.name, user_table.c.fullname, subq.c.count).join_from(
... user_table, subq
... )
>>> print(stmt)
WITH anon_1 AS
(SELECT count(address.id) AS count, address.user_id AS user_id
FROM address GROUP BY address.user_id)
SELECT user_account.name, user_account.fullname, anon_1.count
FROM user_account JOIN anon_1 ON user_account.id = anon_1.user_id
The CTE
construct also features the ability to be used
in a “recursive” style, and may in more elaborate cases be composed from the
RETURNING clause of an INSERT, UPDATE or DELETE statement. The docstring
for CTE
includes details on these additional patterns.
In both cases, the subquery and CTE were named at the SQL level using an
“anonymous” name. In the Python code, we don’t need to provide these names
at all. The object identity of the Subquery
or CTE
instances serves as the syntactical identity of the object when rendered.
A name that will be rendered in the SQL can be provided by passing it as the
first argument of the Select.subquery()
or Select.cte()
methods.
See also
Select.subquery()
- further detail on subqueries
Select.cte()
- examples for CTE including how to use
RECURSIVE as well as DML-oriented CTEs
ORM Entity Subqueries/CTEs
In the ORM, the aliased()
construct may be used to associate an ORM
entity, such as our User
or Address
class, with any FromClause
concept that represents a source of rows. The preceding section
ORM Entity Aliases illustrates using aliased()
to associate the mapped class with an Alias
of its
mapped Table
. Here we illustrate aliased()
doing the same
thing against both a Subquery
as well as a CTE
generated against a Select
construct, that ultimately derives
from that same mapped Table
.
Below is an example of applying aliased()
to the Subquery
construct, so that ORM entities can be extracted from its rows. The result
shows a series of User
and Address
objects, where the data for
each Address
object ultimately came from a subquery against the
address
table rather than that table directly:
>>> subq = select(Address).where(~Address.email_address.like("%@aol.com")).subquery()
>>> address_subq = aliased(Address, subq)
>>> stmt = (
... select(User, address_subq)
... .join_from(User, address_subq)
... .order_by(User.id, address_subq.id)
... )
>>> with Session(engine) as session:
... for user, address in session.execute(stmt):
... print(f"{user} {address}")
BEGIN (implicit)
SELECT user_account.id, user_account.name, user_account.fullname,
anon_1.id AS id_1, anon_1.email_address, anon_1.user_id
FROM user_account JOIN
(SELECT address.id AS id, address.email_address AS email_address, address.user_id AS user_id
FROM address
WHERE address.email_address NOT LIKE ?) AS anon_1 ON user_account.id = anon_1.user_id
ORDER BY user_account.id, anon_1.id
[...] ('%@aol.com',)
User(id=1, name='spongebob', fullname='Spongebob Squarepants') Address(id=1, email_address='[email protected]')
User(id=2, name='sandy', fullname='Sandy Cheeks') Address(id=2, email_address='[email protected]')
User(id=2, name='sandy', fullname='Sandy Cheeks') Address(id=3, email_address='[email protected]')
ROLLBACK
Another example follows, which is exactly the same except it makes use of the
CTE
construct instead: