Selectables, Tables, FROM objects

The term “selectable” refers to any object that rows can be selected from; in SQLAlchemy, these objects descend from FromClause and their distinguishing feature is their FromClause.c attribute, which is a namespace of all the columns contained within the FROM clause (these elements are themselves ColumnElement subclasses).

Selectable Foundational Constructors

Top level “FROM clause” and “SELECT” constructors.

Object Name Description

except_(*selects, **kwargs)

Return an EXCEPT of multiple selectables.

except_all(*selects, **kwargs)

Return an EXCEPT ALL of multiple selectables.

exists(*args, **kwargs)

Construct a new Exists construct.

intersect(*selects, **kwargs)

Return an INTERSECT of multiple selectables.

intersect_all(*selects, **kwargs)

Return an INTERSECT ALL of multiple selectables.

select(*args, **kw)

Create a Select using either the 1.x or 2.0 constructor style.

table(name, *columns, **kw)

Produce a new TableClause.

union(*selects, **kwargs)

Return a UNION of multiple selectables.

union_all(*selects, **kwargs)

Return a UNION ALL of multiple selectables.

values(*columns, **kw)

Construct a Values construct.

function sqlalchemy.sql.expression.except_(*selects, **kwargs)

Return an EXCEPT of multiple selectables.

The returned object is an instance of CompoundSelect.

Parameters:
  • *selects – a list of Select instances.

  • **kwargs – available keyword arguments are the same as those of select().

function sqlalchemy.sql.expression.except_all(*selects, **kwargs)

Return an EXCEPT ALL of multiple selectables.

The returned object is an instance of CompoundSelect.

Parameters:
  • *selects – a list of Select instances.

  • **kwargs – available keyword arguments are the same as those of select().

function sqlalchemy.sql.expression.exists(*args, **kwargs)

Construct a new Exists construct.

The exists() can be invoked by itself to produce an Exists construct, which will accept simple WHERE criteria:

exists_criteria = exists().where(table1.c.col1 == table2.c.col2)

However, for greater flexibility in constructing the SELECT, an existing Select construct may be converted to an Exists, most conveniently by making use of the SelectBase.exists() method:

exists_criteria = (
    select(table2.c.col2).
    where(table1.c.col1 == table2.c.col2).
    exists()
)

The EXISTS criteria is then used inside of an enclosing SELECT:

stmt = select(table1.c.col1).where(exists_criteria)

The above statement will then be of the form:

SELECT col1 FROM table1 WHERE EXISTS
(SELECT table2.col2 FROM table2 WHERE table2.col2 = table1.col1)

See also

EXISTS subqueries - in the 2.0 style tutorial.

SelectBase.exists() - method to transform a SELECT to an EXISTS clause.

function sqlalchemy.sql.expression.intersect(*selects, **kwargs)

Return an INTERSECT of multiple selectables.

The returned object is an instance of CompoundSelect.

Parameters:
  • *selects – a list of Select instances.

  • **kwargs – available keyword arguments are the same as those of select().

function sqlalchemy.sql.expression.intersect_all(*selects, **kwargs)

Return an INTERSECT ALL of multiple selectables.

The returned object is an instance of CompoundSelect.

Parameters:
  • *selects – a list of Select instances.

  • **kwargs – available keyword arguments are the same as those of select().

function sqlalchemy.sql.expression.select(*args, **kw)

Create a Select using either the 1.x or 2.0 constructor style.

For the legacy calling style, see Select.create_legacy_select(). If the first argument passed is a Python sequence or if keyword arguments are present, this style is used.

New in version 2.0: - the select() construct is the same construct as the one returned by select(), except that the function only accepts the “columns clause” entities up front; the rest of the state of the SELECT should be built up using generative methods.

Similar functionality is also available via the FromClause.select() method on any FromClause.

See also

Selecting - Core Tutorial description of select().

Parameters:

*entities

Entities to SELECT from. For Core usage, this is typically a series of ColumnElement and / or FromClause objects which will form the columns clause of the resulting statement. For those objects that are instances of FromClause (typically Table or Alias objects), the FromClause.c collection is extracted to form a collection of ColumnElement objects.

This parameter will also accept TextClause constructs as given, as well as ORM-mapped classes.

function sqlalchemy.sql.expression.table(name, *columns, **kw)

Produce a new TableClause.

The object returned is an instance of TableClause, which represents the “syntactical” portion of the schema-level Table object. It may be used to construct lightweight table constructs.

Changed in version 1.0.0: table() can now be imported from the plain sqlalchemy namespace like any other SQL element.

Parameters:
  • name – Name of the table.

  • columns – A collection of column() constructs.

  • schema

    The schema name for this table.

    New in version 1.3.18: table() can now accept a schema argument.

function sqlalchemy.sql.expression.union(*selects, **kwargs)

Return a UNION of multiple selectables.

The returned object is an instance of CompoundSelect.

A similar union() method is available on all FromClause subclasses.

Parameters:
  • *selects – a list of Select instances.

  • **kwargs – available keyword arguments are the same as those of select().

function sqlalchemy.sql.expression.union_all(*selects, **kwargs)

Return a UNION ALL of multiple selectables.

The returned object is an instance of CompoundSelect.

A similar union_all() method is available on all FromClause subclasses.

Parameters:
  • *selects – a list of Select instances.

  • **kwargs – available keyword arguments are the same as those of select().

function sqlalchemy.sql.expression.values(*columns, **kw)

Construct a Values construct.

The column expressions and the actual data for Values are given in two separate steps. The constructor receives the column expressions typically as column() constructs, and the data is then passed via the Values.data() method as a list, which can be called multiple times to add more data, e.g.:

from sqlalchemy import column
from sqlalchemy import values

value_expr = values(
    column('id', Integer),
    column('name', String),
    name="my_values"
).data(
    [(1, 'name1'), (2, 'name2'), (3, 'name3')]
)
Parameters:
  • *columns – column expressions, typically composed using column() objects.

  • name – the name for this VALUES construct. If omitted, the VALUES construct will be unnamed in a SQL expression. Different backends may have different requirements here.

  • literal_binds – Defaults to False. Whether or not to render the data values inline in the SQL output, rather than using bound parameters.

Selectable Modifier Constructors

Functions listed here are more commonly available as methods from FromClause and Selectable elements, for example, the alias() function is usually invoked via the FromClause.alias() method.

Object Name Description

alias(selectable[, name, flat])

Return an Alias object.

cte(selectable[, name, recursive])

Return a new CTE, or Common Table Expression instance.

join(left, right[, onclause, isouter, ...])

Produce a Join object, given two FromClause expressions.

lateral(selectable[, name])

Return a Lateral object.

outerjoin(left, right[, onclause, full])

Return an OUTER JOIN clause element.

tablesample(selectable, sampling[, name, seed])

Return a TableSample object.

function sqlalchemy.sql.expression.alias(selectable, name=None, flat=False)

Return an Alias object.

An Alias represents any FromClause with an alternate name assigned within SQL, typically using the AS clause when generated, e.g. SELECT * FROM table AS aliasname.

Similar functionality is available via the FromClause.alias() method available on all FromClause subclasses. In terms of a SELECT object as generated from the select() function, the SelectBase.alias() method returns an Alias or similar object which represents a named, parenthesized subquery.

When an Alias is created from a Table object, this has the effect of the table being rendered as tablename AS aliasname in a SELECT statement.

For select() objects, the effect is that of creating a named subquery, i.e. (select ...) AS aliasname.

The name parameter is optional, and provides the name to use in the rendered SQL. If blank, an “anonymous” name will be deterministically generated at compile time. Deterministic means the name is guaranteed to be unique against other constructs used in the same statement, and will also be the same name for each successive compilation of the same statement object.

Parameters:
  • selectable – any FromClause subclass, such as a table, select statement, etc.

  • name – string name to be assigned as the alias. If None, a name will be deterministically generated at compile time.

  • flat – Will be passed through to if the given selectable is an instance of Join - see Join.alias() for details.

function sqlalchemy.sql.expression.cte(selectable, name=None, recursive=False)

Return a new CTE, or Common Table Expression instance.

Please see HasCTE.cte() for detail on CTE usage.

function sqlalchemy.sql.expression.join(left, right, onclause=None, isouter=False, full=False)

Produce a Join object, given two FromClause expressions.

E.g.:

j = join(user_table, address_table,
         user_table.c.id == address_table.c.user_id)
stmt = select(user_table).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id

Similar functionality is available given any FromClause object (e.g. such as a Table) using the FromClause.join() method.

Parameters:
  • left – The left side of the join.

  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.

  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.

  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.

  • full

    if True, render a FULL OUTER JOIN, instead of JOIN.

    New in version 1.1.

See also

FromClause.join() - method form, based on a given left side.

Join - the type of object produced.

function sqlalchemy.sql.expression.lateral(selectable, name=None)

Return a Lateral object.

Lateral is an 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.

New in version 1.1.

See also

LATERAL correlation - overview of usage.

function sqlalchemy.sql.expression.outerjoin(left, right, onclause=None, full=False)

Return an OUTER JOIN clause element.

The returned object is an instance of Join.

Similar functionality is also available via the FromClause.outerjoin() method on any FromClause.

Parameters:
  • left – The left side of the join.

  • right – The right side of the join.

  • onclause – Optional criterion for the ON clause, is derived from foreign key relationships established between left and right otherwise.

To chain joins together, use the FromClause.join() or FromClause.outerjoin() methods on the resulting Join object.

function sqlalchemy.sql.expression.tablesample(selectable, sampling, name=None, seed=None)

Return a TableSample object.

TableSample is an Alias subclass that represents a table with the TABLESAMPLE clause applied to it. tablesample() is also available from the FromClause class via the FromClause.tablesample() method.

The TABLESAMPLE clause allows selecting a randomly selected approximate percentage of rows from a table. It supports multiple sampling methods, most commonly BERNOULLI and SYSTEM.

e.g.:

from sqlalchemy import func

selectable = people.tablesample(
            func.bernoulli(1),
            name='alias',
            seed=func.random())
stmt = select(selectable.c.people_id)

Assuming people with a column people_id, the above statement would render as:

SELECT alias.people_id FROM
people AS alias TABLESAMPLE bernoulli(:bernoulli_1)
REPEATABLE (random())

New in version 1.1.

Parameters:
  • sampling – a float percentage between 0 and 100 or Function.

  • name – optional alias name

  • seed – any real-valued SQL expression. When specified, the REPEATABLE sub-clause is also rendered.

Selectable Class Documentation

The classes here are generated using the constructors listed at Selectable Foundational Constructors and Selectable Modifier Constructors.

Object Name Description

Alias

Represents an table or selectable alias (AS).

AliasedReturnsRows

Base class of aliases against tables, subqueries, and other selectables.

CompoundSelect

Forms the basis of UNION, UNION ALL, and other SELECT-based set operations.

CTE

Represent a Common Table Expression.

Executable

Mark a ClauseElement as supporting execution.

Exists

Represent an EXISTS clause.

FromClause

Represent an element that can be used within the FROM clause of a SELECT statement.

GenerativeSelect

Base class for SELECT statements where additional elements can be added.

HasCTE

Mixin that declares a class to include CTE support.

HasPrefixes

HasSuffixes

Join

Represent a JOIN construct between two FromClause elements.

Lateral

Represent a LATERAL subquery.

ReturnsRows

The base-most class for Core constructs that have some concept of columns that can represent rows.

ScalarSelect

Represent a scalar subquery.

Select

Represents a SELECT statement.

Selectable

Mark a class as being selectable.

SelectBase

Base class for SELECT statements.

Subquery

Represent a subquery of a SELECT.

TableClause

Represents a minimal “table” construct.

TableSample

Represent a TABLESAMPLE clause.

TableValuedAlias

An alias against a “table valued” SQL function.

TextualSelect

Wrap a TextClause construct within a SelectBase interface.

Values

Represent a VALUES construct that can be used as a FROM element in a statement.

class sqlalchemy.sql.expression.Alias(*arg, **kw)

Represents an table or selectable alias (AS).

Represents an alias, as typically applied to any table or sub-select within a SQL statement using the AS keyword (or without the keyword on certain databases such as Oracle).

This object is constructed from the alias() module level function as well as the FromClause.alias() method available on all FromClause subclasses.

Members

inherit_cache

Class signature

class sqlalchemy.sql.expression.Alias (sqlalchemy.sql.roles.DMLTableRole, sqlalchemy.sql.expression.AliasedReturnsRows)

attribute sqlalchemy.sql.expression.Alias.inherit_cache = True

Indicate if this HasCacheKey instance should make use of the cache key generation scheme used by its immediate superclass.

The attribute defaults to None, which indicates that a construct has not yet taken into account whether or not its appropriate for it to participate in caching; this is functionally equivalent to setting the value to False, except that a warning is also emitted.

This flag can be set to True on a particular class, if the SQL that corresponds to the object does not change based on attributes which are local to this class, and not its superclass.

See also

Enabling Caching Support for Custom Constructs - General guideslines for setting the HasCacheKey.inherit_cache attribute for third-party or user defined SQL constructs.

class sqlalchemy.sql.expression.AliasedReturnsRows(*arg, **kw)

Base class of aliases against tables, subqueries, and other selectables.

Class signature

class sqlalchemy.sql.expression.AliasedReturnsRows (sqlalchemy.sql.expression.NoInit, sqlalchemy.sql.expression.FromClause)

attribute sqlalchemy.sql.expression.AliasedReturnsRows.description
method sqlalchemy.sql.expression.AliasedReturnsRows.is_derived_from(fromclause)

Return True if this FromClause is ‘derived’ from the given FromClause.

An example would be an Alias of a Table is derived from that Table.

attribute sqlalchemy.sql.expression.AliasedReturnsRows.original

Legacy for dialects that are referring to Alias.original.

class sqlalchemy.sql.expression.CompoundSelect(keyword, *selects, **kwargs)

Forms the basis of UNION, UNION ALL, and other SELECT-based set operations.

Class signature

class sqlalchemy.sql.expression.CompoundSelect (sqlalchemy.sql.expression.HasCompileState, sqlalchemy.sql.expression.GenerativeSelect)

method sqlalchemy.sql.expression.CompoundSelect.add_cte(cte)

inherited from the HasCTE.add_cte() method of HasCTE

Add a CTE to this statement object that will be independently rendered even if not referenced in the statement otherwise.

This feature is useful for the use case of embedding a DML statement such as an INSERT or UPDATE as a CTE inline with a primary statement that may draw from its results indirectly; while PostgreSQL is known to support this usage, it may not be supported by other backends.

E.g.:

from sqlalchemy import table, column, select
t = table('t', column('c1'), column('c2'))

ins = t.insert().values({"c1": "x", "c2": "y"}).cte()

stmt = select(t).add_cte(ins)

Would render:

WITH anon_1 AS
(INSERT INTO t (c1, c2) VALUES (:param_1, :param_2))
SELECT t.c1, t.c2
FROM t

Above, the “anon_1” CTE is not referred towards in the SELECT statement, however still accomplishes the task of running an INSERT statement.

Similarly in a DML-related context, using the PostgreSQL Insert construct to generate an “upsert”:

from sqlalchemy import table, column
from sqlalchemy.dialects.postgresql import insert

t = table("t", column("c1"), column("c2"))

delete_statement_cte = (
    t.delete().where(t.c.c1 < 1).cte("deletions")
)

insert_stmt = insert(t).values({"c1": 1, "c2": 2})
update_statement = insert_stmt.on_conflict_do_update(
    index_elements=[t.c.c1],
    set_={
        "c1": insert_stmt.excluded.c1,
        "c2": insert_stmt.excluded.c2,
    },
).add_cte(delete_statement_cte)

print(update_statement)

The above statement renders as:

WITH deletions AS
(DELETE FROM t WHERE t.c1 < %(c1_1)s)
INSERT INTO t (c1, c2) VALUES (%(c1)s, %(c2)s)
ON CONFLICT (c1) DO UPDATE SET c1 = excluded.c1, c2 = excluded.c2

New in version 1.4.21.

method sqlalchemy.sql.expression.CompoundSelect.alias(name=None, flat=False)

inherited from the SelectBase.alias() method of SelectBase

Return a named subquery against this SelectBase.

For a SelectBase (as opposed to a FromClause), this returns a Subquery object which behaves mostly the same as the Alias object that is used with a FromClause.

Changed in version 1.4: The SelectBase.alias() method is now a synonym for the SelectBase.subquery() method.

method sqlalchemy.sql.expression.CompoundSelect.append_group_by(*clauses)

inherited from the DeprecatedSelectBaseGenerations.append_group_by() method of DeprecatedSelectBaseGenerations

Append the given GROUP BY criterion applied to this selectable.

Deprecated since version 1.4: The GenerativeSelect.append_group_by() method is deprecated and will be removed in a future release. Use the generative method GenerativeSelect.group_by().

The criterion will be appended to any pre-existing GROUP BY criterion.

This is an in-place mutation method; the GenerativeSelect.group_by() method is preferred, as it provides standard method chaining.

method sqlalchemy.sql.expression.CompoundSelect.append_order_by(*clauses)

inherited from the DeprecatedSelectBaseGenerations.append_order_by() method of DeprecatedSelectBaseGenerations

Append the given ORDER BY criterion applied to this selectable.

Deprecated since version 1.4: The GenerativeSelect.append_order_by() method is deprecated and will be removed in a future release. Use the generative method GenerativeSelect.order_by().

The criterion will be appended to any pre-existing ORDER BY criterion.

This is an in-place mutation method; the GenerativeSelect.order_by() method is preferred, as it provides standard method chaining.

method sqlalchemy.sql.expression.CompoundSelect.apply_labels()

inherited from the GenerativeSelect.apply_labels() method of GenerativeSelect

Deprecated since version 1.4: The GenerativeSelect.apply_labels() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Use set_label_style(LABEL_STYLE_TABLENAME_PLUS_COL) instead. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

method sqlalchemy.sql.expression.CompoundSelect.as_scalar()

inherited from the SelectBase.as_scalar() method of SelectBase

Deprecated since version 1.4: The SelectBase.as_scalar() method is deprecated and will be removed in a future release. Please refer to SelectBase.scalar_subquery().

attribute sqlalchemy.sql.expression.CompoundSelect.bind

Returns the Engine or Connection to which this Executable is bound, or None if none found.

Deprecated since version 1.4: The Executable.bind attribute is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Bound metadata is being removed as of SQLAlchemy 2.0. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

attribute sqlalchemy.sql.expression.CompoundSelect.c

inherited from the SelectBase.c attribute of SelectBase

Deprecated since version 1.4: The SelectBase.c and SelectBase.columns attributes are deprecated and will be removed in a future release; these attributes implicitly create a subquery that should be explicit. Please call SelectBase.subquery() first in order to create a subquery, which then contains this attribute. To access the columns that this SELECT object SELECTs from, use the SelectBase.selected_columns attribute.

method sqlalchemy.sql.expression.CompoundSelect.corresponding_column(column, require_embedded=False)

inherited from the Selectable.corresponding_column() method of Selectable

Given a ColumnElement, return the exported ColumnElement object from the Selectable.exported_columns collection of this Selectable which corresponds to that original ColumnElement via a common ancestor column.

Parameters:
  • column – the target ColumnElement to be matched.

  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this Selectable. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this Selectable.

See also

Selectable.exported_columns - the ColumnCollection that is used for the operation.

ColumnCollection.corresponding_column() - implementation method.

method sqlalchemy.sql.expression.CompoundSelect.cte(name=None, recursive=False, nesting=False)

inherited from the HasCTE.cte() method of HasCTE

Return a new CTE, or Common Table Expression instance.

Common table expressions are a SQL standard whereby SELECT statements can draw upon secondary statements specified along with the primary statement, using a clause called “WITH”. Special semantics regarding UNION can also be employed to allow “recursive” queries, where a SELECT statement can draw upon the set of rows that have previously been selected.

CTEs can also be applied to DML constructs UPDATE, INSERT and DELETE on some databases, both as a source of CTE rows when combined with RETURNING, as well as a consumer of CTE rows.

Changed in version 1.1: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.

SQLAlchemy detects CTE objects, which are treated similarly to Alias objects, as special elements to be delivered to the FROM clause of the statement as well as to a WITH clause at the top of the statement.

For special prefixes such as PostgreSQL “MATERIALIZED” and “NOT MATERIALIZED”, the CTE.prefix_with() method may be used to establish these.

Changed in version 1.3.13: Added support for prefixes. In particular - MATERIALIZED and NOT MATERIALIZED.

Parameters:
  • name – name given to the common table expression. Like FromClause.alias(), the name can be left as None in which case an anonymous symbol will be used at query compile time.

  • recursive – if True, will render WITH RECURSIVE. A recursive common table expression is intended to be used in conjunction with UNION ALL in order to derive rows from those already selected.

  • nesting

    if True, will render the CTE locally to the actual statement.

    New in version 1.4.24.

The following examples include two from PostgreSQL’s documentation at https://www.postgresql.org/docs/current/static/queries-with.html, as well as additional examples.

Example 1, non recursive:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

orders = Table('orders', metadata,
    Column('region', String),
    Column('amount', Integer),
    Column('product', String),
    Column('quantity', Integer)
)

regional_sales = select(
                    orders.c.region,
                    func.sum(orders.c.amount).label('total_sales')
                ).group_by(orders.c.region).cte("regional_sales")


top_regions = select(regional_sales.c.region).\
        where(
            regional_sales.c.total_sales >
            select(
                func.sum(regional_sales.c.total_sales) / 10
            )
        ).cte("top_regions")

statement = select(
            orders.c.region,
            orders.c.product,
            func.sum(orders.c.quantity).label("product_units"),
            func.sum(orders.c.amount).label("product_sales")
    ).where(orders.c.region.in_(
        select(top_regions.c.region)
    )).group_by(orders.c.region, orders.c.product)

result = conn.execute(statement).fetchall()

Example 2, WITH RECURSIVE:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

parts = Table('parts', metadata,
    Column('part', String),
    Column('sub_part', String),
    Column('quantity', Integer),
)

included_parts = select(\
    parts.c.sub_part, parts.c.part, parts.c.quantity\
    ).\
    where(parts.c.part=='our part').\
    cte(recursive=True)


incl_alias = included_parts.alias()
parts_alias = parts.alias()
included_parts = included_parts.union_all(
    select(
        parts_alias.c.sub_part,
        parts_alias.c.part,
        parts_alias.c.quantity
    ).\
    where(parts_alias.c.part==incl_alias.c.sub_part)
)

statement = select(
            included_parts.c.sub_part,
            func.sum(included_parts.c.quantity).
              label('total_quantity')
        ).\
        group_by(included_parts.c.sub_part)

result = conn.execute(statement).fetchall()

Example 3, an upsert using UPDATE and INSERT with CTEs:

from datetime import date
from sqlalchemy import (MetaData, Table, Column, Integer,
                        Date, select, literal, and_, exists)

metadata = MetaData()

visitors = Table('visitors', metadata,
    Column('product_id', Integer, primary_key=True),
    Column('date', Date, primary_key=True),
    Column('count', Integer),
)

# add 5 visitors for the product_id == 1
product_id = 1
day = date.today()
count = 5

update_cte = (
    visitors.update()
    .where(and_(visitors.c.product_id == product_id,
                visitors.c.date == day))
    .values(count=visitors.c.count + count)
    .returning(literal(1))
    .cte('update_cte')
)

upsert = visitors.insert().from_select(
    [visitors.c.product_id, visitors.c.date, visitors.c.count],
    select(literal(product_id), literal(day), literal(count))
        .where(~exists(update_cte.select()))
)

connection.execute(upsert)

Example 4, Nesting CTE (SQLAlchemy 1.4.24 and above):

value_a = select(
    literal("root").label("n")
).cte("value_a")

# A nested CTE with the same name as the root one
value_a_nested = select(
    literal("nesting").label("n")
).cte("value_a", nesting=True)

# Nesting CTEs takes ascendency locally
# over the CTEs at a higher level
value_b = select(value_a_nested.c.n).cte("value_b")

value_ab = select(value_a.c.n.label("a"), value_b.c.n.label("b"))

The above query will render the second CTE nested inside the first, shown with inline parameters below as:

WITH
    value_a AS
        (SELECT 'root' AS n),
    value_b AS
        (WITH value_a AS
            (SELECT 'nesting' AS n)
        SELECT value_a.n AS n FROM value_a)
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

See also

Query.cte() - ORM version of HasCTE.cte().

method sqlalchemy.sql.expression.CompoundSelect.execute(*multiparams, **params)

inherited from the Executable.execute() method of Executable

Compile and execute this Executable.

Deprecated since version 1.4: The Executable.execute() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. All statement execution in SQLAlchemy 2.0 is performed by the Connection.execute() method of Connection, or in the ORM by the Session.execute() method of Session. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

method sqlalchemy.sql.expression.CompoundSelect.execution_options(**kw)

inherited from the Executable.execution_options() method of Executable

Set non-SQL options for the statement which take effect during execution.

Execution options can be set on a per-statement or per Connection basis. Additionally, the Engine and ORM Query objects provide access to execution options which they in turn configure upon connections.

The execution_options() method is generative. A new instance of this statement is returned that contains the options:

statement = select(table.c.x, table.c.y)
statement = statement.execution_options(autocommit=True)

Note that only a subset of possible execution options can be applied to a statement - these include “autocommit” and “stream_results”, but not “isolation_level” or “compiled_cache”. See Connection.execution_options() for a full list of possible options.

method sqlalchemy.sql.expression.CompoundSelect.exists()

inherited from the SelectBase.exists() method of SelectBase

Return an Exists representation of this selectable, which can be used as a column expression.

The returned object is an instance of Exists.

See also

exists()

EXISTS subqueries - in the 2.0 style tutorial.

New in version 1.4.

attribute sqlalchemy.sql.expression.CompoundSelect.exported_columns

inherited from the SelectBase.exported_columns attribute of SelectBase

A ColumnCollection that represents the “exported” columns of this Selectable, not including TextClause constructs.

The “exported” columns for a SelectBase object are synonymous with the SelectBase.selected_columns collection.

New in version 1.4.

method sqlalchemy.sql.expression.CompoundSelect.fetch(count, with_ties=False, percent=False)

inherited from the GenerativeSelect.fetch() method of GenerativeSelect

Return a new selectable with the given FETCH FIRST criterion applied.

This is a numeric value which usually renders as FETCH {FIRST | NEXT} [ count ] {ROW | ROWS} {ONLY | WITH TIES} expression in the resulting select. This functionality is is currently implemented for Oracle, PostgreSQL, MSSQL.

Use GenerativeSelect.offset() to specify the offset.

Note

The GenerativeSelect.fetch() method will replace any clause applied with GenerativeSelect.limit().

New in version 1.4.

Parameters:
  • count – an integer COUNT parameter, or a SQL expression that provides an integer result. When percent=True this will represent the percentage of rows to return, not the absolute value. Pass None to reset it.

  • with_ties – When True, the WITH TIES option is used to return any additional rows that tie for the last place in the result set according to the ORDER BY clause. The ORDER BY may be mandatory in this case. Defaults to False

  • percent – When True, count represents the percentage of the total number of selected rows to return. Defaults to False

method sqlalchemy.sql.expression.CompoundSelect.get_execution_options()

inherited from the Executable.get_execution_options() method of Executable

Get the non-SQL options which will take effect during execution.

New in version 1.3.

method sqlalchemy.sql.expression.CompoundSelect.get_label_style()

Retrieve the current label style.

New in version 1.4.

method sqlalchemy.sql.expression.CompoundSelect.group_by(*clauses)

inherited from the GenerativeSelect.group_by() method of GenerativeSelect

Return a new selectable with the given list of GROUP BY criterion applied.

All existing GROUP BY settings can be suppressed by passing None.

e.g.:

stmt = select(table.c.name, func.max(table.c.stat)).\
group_by(table.c.name)
Parameters:

*clauses – a series of ColumnElement constructs which will be used to generate an GROUP BY clause.

method sqlalchemy.sql.expression.CompoundSelect.label(name)

inherited from the SelectBase.label() method of SelectBase

Return a ‘scalar’ representation of this selectable, embedded as a subquery with a label.

method sqlalchemy.sql.expression.CompoundSelect.lateral(name=None)

inherited from the SelectBase.lateral() method of SelectBase

Return a LATERAL alias of this Selectable.

The return value is the Lateral construct also provided by the top-level lateral() function.

New in version 1.1.

See also

LATERAL correlation - overview of usage.

method sqlalchemy.sql.expression.CompoundSelect.limit(limit)

inherited from the GenerativeSelect.limit() method of GenerativeSelect

Return a new selectable with the given LIMIT criterion applied.

This is a numerical value which usually renders as a LIMIT expression in the resulting select. Backends that don’t support LIMIT will attempt to provide similar functionality.

Note

The GenerativeSelect.limit() method will replace any clause applied with GenerativeSelect.fetch().

Changed in version 1.0.0: - Select.limit() can now accept arbitrary SQL expressions as well as integer values.

Parameters:

limit – an integer LIMIT parameter, or a SQL expression that provides an integer result. Pass None to reset it.

method sqlalchemy.sql.expression.CompoundSelect.offset(offset)

inherited from the GenerativeSelect.offset() method of GenerativeSelect

Return a new selectable with the given OFFSET criterion applied.

This is a numeric value which usually renders as an OFFSET expression in the resulting select. Backends that don’t support OFFSET will attempt to provide similar functionality.

Changed in version 1.0.0: - Select.offset() can now accept arbitrary SQL expressions as well as integer values.

Parameters:

offset – an integer OFFSET parameter, or a SQL expression that provides an integer result. Pass None to reset it.

method sqlalchemy.sql.expression.CompoundSelect.options(*options)

inherited from the Executable.options() method of Executable

Apply options to this statement.

In the general sense, options are any kind of Python object that can be interpreted by the SQL compiler for the statement. These options can be consumed by specific dialects or specific kinds of compilers.

The most commonly known kind of option are the ORM level options that apply “eager load” and other loading behaviors to an ORM query. However, options can theoretically be used for many other purposes.

For background on specific kinds of options for specific kinds of statements, refer to the documentation for those option objects.

Changed in version 1.4: - added Generative.options() to Core statement objects towards the goal of allowing unified Core / ORM querying capabilities.

See also

Deferred Column Loader Query Options - refers to options specific to the usage of ORM queries

Relationship Loading with Loader Options - refers to options specific to the usage of ORM queries

method sqlalchemy.sql.expression.CompoundSelect.order_by(*clauses)

inherited from the GenerativeSelect.order_by() method of GenerativeSelect

Return a new selectable with the given list of ORDER BY criteria applied.

e.g.:

stmt = select(table).order_by(table.c.id, table.c.name)

Calling this method multiple times is equivalent to calling it once with all the clauses concatenated. All existing ORDER BY criteria may be cancelled by passing None by itself. New ORDER BY criteria may then be added by invoking Query.order_by() again, e.g.:

# will erase all ORDER BY and ORDER BY new_col alone
stmt = stmt.order_by(None).order_by(new_col)
Parameters:

*clauses – a series of ColumnElement constructs which will be used to generate an ORDER BY clause.

method sqlalchemy.sql.expression.CompoundSelect.replace_selectable(old, alias)

inherited from the Selectable.replace_selectable() method of Selectable

Replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

Deprecated since version 1.4: The Selectable.replace_selectable() method is deprecated, and will be removed in a future release. Similar functionality is available via the sqlalchemy.sql.visitors module.

method sqlalchemy.sql.expression.CompoundSelect.scalar(*multiparams, **params)

inherited from the Executable.scalar() method of Executable

Compile and execute this Executable, returning the result’s scalar representation.

Deprecated since version 1.4: The Executable.scalar() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Scalar execution in SQLAlchemy 2.0 is performed by the Connection.scalar() method of Connection, or in the ORM by the Session.scalar() method of Session. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

method sqlalchemy.sql.expression.CompoundSelect.scalar_subquery()

inherited from the SelectBase.scalar_subquery() method of SelectBase

Return a ‘scalar’ representation of this selectable, which can be used as a column expression.

The returned object is an instance of ScalarSelect.

Typically, a select statement which has only one column in its columns clause is eligible to be used as a scalar expression. The scalar subquery can then be used in the WHERE clause or columns clause of an enclosing SELECT.

Note that the scalar subquery differentiates from the FROM-level subquery that can be produced using the SelectBase.subquery() method.

See also

Scalar and Correlated Subqueries - in the 2.0 tutorial

method sqlalchemy.sql.expression.CompoundSelect.select(*arg, **kw)

inherited from the SelectBase.select() method of SelectBase

Deprecated since version 1.4: The SelectBase.select() method is deprecated and will be removed in a future release; this method implicitly creates a subquery that should be explicit. Please call SelectBase.subquery() first in order to create a subquery, which then can be selected.

attribute sqlalchemy.sql.expression.CompoundSelect.selected_columns

A ColumnCollection representing the columns that this SELECT statement or similar construct returns in its result set, not including TextClause constructs.

For a CompoundSelect, the CompoundSelect.selected_columns attribute returns the selected columns of the first SELECT statement contained within the series of statements within the set operation.

New in version 1.4.

method sqlalchemy.sql.expression.CompoundSelect.self_group(against=None)

Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a “grouping” construct, i.e. parenthesis. In particular it’s used by “binary” expressions to provide a grouping around themselves when placed into a larger expression, as well as by select() constructs when placed into the FROM clause of another select(). (Note that subqueries should be normally created using the Select.alias() method, as many platforms require nested SELECT statements to be named).

As expressions are composed together, the application of self_group() is automatic - end-user code should never need to use this method directly. Note that SQLAlchemy’s clause constructs take operator precedence into account - so parenthesis might not be needed, for example, in an expression like x OR (y AND z) - AND takes precedence over OR.

The base self_group() method of ClauseElement just returns self.

method sqlalchemy.sql.expression.CompoundSelect.set_label_style(style)

Return a new selectable with the specified label style.

There are three “label styles” available, LABEL_STYLE_DISAMBIGUATE_ONLY, LABEL_STYLE_TABLENAME_PLUS_COL, and LABEL_STYLE_NONE. The default style is LABEL_STYLE_DISAMBIGUATE_ONLY.

In modern SQLAlchemy, there is not generally a need to change the labeling style, as per-expression labels are more effectively used by making use of the ColumnElement.label() method. In past versions, LABEL_STYLE_TABLENAME_PLUS_COL was used to disambiguate same-named columns from different tables, aliases, or subqueries; the newer LABEL_STYLE_DISAMBIGUATE_ONLY now applies labels only to names that conflict with an existing name so that the impact of this labeling is minimal.

The rationale for disambiguation is mostly so that all column expressions are available from a given FromClause.c collection when a subquery is created.

New in version 1.4: - the GenerativeSelect.set_label_style() method replaces the previous combination of .apply_labels(), .with_labels() and use_labels=True methods and/or parameters.

method sqlalchemy.sql.expression.CompoundSelect.slice(start, stop)

inherited from the GenerativeSelect.slice() method of GenerativeSelect

Apply LIMIT / OFFSET to this statement based on a slice.

The start and stop indices behave like the argument to Python’s built-in range() function. This method provides an alternative to using LIMIT/OFFSET to get a slice of the query.

For example,

stmt = select(User).order_by(User.id).slice(1, 3)

renders as

SELECT users.id AS users_id,
       users.name AS users_name
FROM users ORDER BY users.id
LIMIT ? OFFSET ?
(2, 1)

Note

The GenerativeSelect.slice() method will replace any clause applied with GenerativeSelect.fetch().

New in version 1.4: Added the GenerativeSelect.slice() method generalized from the ORM.

method sqlalchemy.sql.expression.CompoundSelect.subquery(name=None)

inherited from the SelectBase.subquery() method of SelectBase

Return a subquery of this SelectBase.

A subquery is from a SQL perspective a parenthesized, named construct that can be placed in the FROM clause of another SELECT statement.

Given a SELECT statement such as:

stmt = select(table.c.id, table.c.name)

The above statement might look like:

SELECT table.id, table.name FROM table

The subquery form by itself renders the same way, however when embedded into the FROM clause of another SELECT statement, it becomes a named sub-element:

subq = stmt.subquery()
new_stmt = select(subq)

The above renders as:

SELECT anon_1.id, anon_1.name
FROM (SELECT table.id, table.name FROM table) AS anon_1

Historically, SelectBase.subquery() is equivalent to calling the FromClause.alias() method on a FROM object; however, as a SelectBase object is not directly FROM object, the SelectBase.subquery() method provides clearer semantics.

New in version 1.4.

method sqlalchemy.sql.expression.CompoundSelect.with_for_update(nowait=False, read=False, of=None, skip_locked=False, key_share=False)

Specify a FOR UPDATE clause for this GenerativeSelect.

E.g.:

stmt = select(table).with_for_update(nowait=True)

On a database like PostgreSQL or Oracle, the above would render a statement like:

SELECT table.a, table.b FROM table FOR UPDATE NOWAIT

on other backends, the nowait option is ignored and instead would produce:

SELECT table.a, table.b FROM table FOR UPDATE

When called with no arguments, the statement will render with the suffix FOR UPDATE. Additional arguments can then be provided which allow for common database-specific variants.

Parameters:
  • nowait – boolean; will render FOR UPDATE NOWAIT on Oracle and PostgreSQL dialects.

  • read – boolean; will render LOCK IN SHARE MODE on MySQL, FOR SHARE on PostgreSQL. On PostgreSQL, when combined with nowait, will render FOR SHARE NOWAIT.

  • of – SQL expression or list of SQL expression elements (typically Column objects or a compatible expression) which will render into a FOR UPDATE OF clause; supported by PostgreSQL and Oracle. May render as a table or as a column depending on backend.

  • skip_locked – boolean, will render FOR UPDATE SKIP LOCKED on Oracle and PostgreSQL dialects or FOR SHARE SKIP LOCKED if read=True is also specified.

  • key_share – boolean, will render FOR NO KEY UPDATE, or if combined with read=True will render FOR KEY SHARE, on the PostgreSQL dialect.

class sqlalchemy.sql.expression.CTE(*arg, **kw)

Represent a Common Table Expression.

The CTE object is obtained using the SelectBase.cte() method from any SELECT statement. A less often available syntax also allows use of the HasCTE.cte() method present on DML constructs such as Insert, Update and Delete. See the HasCTE.cte() method for usage details on CTEs.

See also

Subqueries and CTEs - in the 2.0 tutorial

HasCTE.cte() - examples of calling styles

Class signature

class sqlalchemy.sql.expression.CTE (sqlalchemy.sql.roles.DMLTableRole, sqlalchemy.sql.roles.IsCTERole, sqlalchemy.sql.expression.Generative, sqlalchemy.sql.expression.HasPrefixes, sqlalchemy.sql.expression.HasSuffixes, sqlalchemy.sql.expression.AliasedReturnsRows)

method sqlalchemy.sql.expression.CTE.alias(name=None, flat=False)

Return an Alias of this CTE.

This method is a CTE-specific specialization of the FromClause.alias() method.

method sqlalchemy.sql.expression.CTE.union(*other)

Return a new CTE with a SQL UNION of the original CTE against the given selectables provided as positional arguments.

Parameters:

*other

one or more elements with which to create a UNION.

Changed in version 1.4.28: multiple elements are now accepted.

See also

HasCTE.cte() - examples of calling styles

method sqlalchemy.sql.expression.CTE.union_all(*other)

Return a new CTE with a SQL UNION ALL of the original CTE against the given selectables provided as positional arguments.

Parameters:

*other

one or more elements with which to create a UNION.

Changed in version 1.4.28: multiple elements are now accepted.

See also

HasCTE.cte() - examples of calling styles

class sqlalchemy.sql.expression.Executable

Mark a ClauseElement as supporting execution.

Executable is a superclass for all “statement” types of objects, including select(), delete(), update(), insert(), text().

Class signature

class sqlalchemy.sql.expression.Executable (sqlalchemy.sql.roles.StatementRole, sqlalchemy.sql.expression.Generative)

attribute sqlalchemy.sql.expression.Executable.bind

Returns the Engine or Connection to which this Executable is bound, or None if none found.

Deprecated since version 1.4: The Executable.bind attribute is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Bound metadata is being removed as of SQLAlchemy 2.0. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

This is a traversal which checks locally, then checks among the “from” clauses of associated objects until a bound engine or connection is found.

method sqlalchemy.sql.expression.Executable.execute(*multiparams, **params)

Compile and execute this Executable.

Deprecated since version 1.4: The Executable.execute() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. All statement execution in SQLAlchemy 2.0 is performed by the Connection.execute() method of Connection, or in the ORM by the Session.execute() method of Session. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

method sqlalchemy.sql.expression.Executable.execution_options(**kw)

Set non-SQL options for the statement which take effect during execution.

Execution options can be set on a per-statement or per Connection basis. Additionally, the Engine and ORM Query objects provide access to execution options which they in turn configure upon connections.

The execution_options() method is generative. A new instance of this statement is returned that contains the options:

statement = select(table.c.x, table.c.y)
statement = statement.execution_options(autocommit=True)

Note that only a subset of possible execution options can be applied to a statement - these include “autocommit” and “stream_results”, but not “isolation_level” or “compiled_cache”. See Connection.execution_options() for a full list of possible options.

method sqlalchemy.sql.expression.Executable.get_execution_options()

Get the non-SQL options which will take effect during execution.

New in version 1.3.

method sqlalchemy.sql.expression.Executable.options(*options)

Apply options to this statement.

In the general sense, options are any kind of Python object that can be interpreted by the SQL compiler for the statement. These options can be consumed by specific dialects or specific kinds of compilers.

The most commonly known kind of option are the ORM level options that apply “eager load” and other loading behaviors to an ORM query. However, options can theoretically be used for many other purposes.

For background on specific kinds of options for specific kinds of statements, refer to the documentation for those option objects.

Changed in version 1.4: - added Generative.options() to Core statement objects towards the goal of allowing unified Core / ORM querying capabilities.

See also

Deferred Column Loader Query Options - refers to options specific to the usage of ORM queries

Relationship Loading with Loader Options - refers to options specific to the usage of ORM queries

method sqlalchemy.sql.expression.Executable.scalar(*multiparams, **params)

Compile and execute this Executable, returning the result’s scalar representation.

Deprecated since version 1.4: The Executable.scalar() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Scalar execution in SQLAlchemy 2.0 is performed by the Connection.scalar() method of Connection, or in the ORM by the Session.scalar() method of Session. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

class sqlalchemy.sql.expression.Exists(*args, **kwargs)

Represent an EXISTS clause.

See exists() for a description of usage.

An EXISTS clause can also be constructed from a select() instance by calling SelectBase.exists().

method sqlalchemy.sql.expression.Exists.__init__(*args, **kwargs)

Construct a new Exists object.

This constructor is mirrored as a public API function; see sqlalchemy.sql.expression.exists() for a full usage and argument description.

method sqlalchemy.sql.expression.Exists.correlate(*fromclause)

Apply correlation to the subquery noted by this Exists.

method sqlalchemy.sql.expression.Exists.correlate_except(*fromclause)

Apply correlation to the subquery noted by this Exists.

attribute sqlalchemy.sql.expression.Exists.inherit_cache = True

Indicate if this HasCacheKey instance should make use of the cache key generation scheme used by its immediate superclass.

The attribute defaults to None, which indicates that a construct has not yet taken into account whether or not its appropriate for it to participate in caching; this is functionally equivalent to setting the value to False, except that a warning is also emitted.

This flag can be set to True on a particular class, if the SQL that corresponds to the object does not change based on attributes which are local to this class, and not its superclass.

See also

Enabling Caching Support for Custom Constructs - General guideslines for setting the HasCacheKey.inherit_cache attribute for third-party or user defined SQL constructs.

method sqlalchemy.sql.expression.Exists.select(whereclause=None, **kwargs)

Return a SELECT of this Exists.

e.g.:

stmt = exists(some_table.c.id).where(some_table.c.id == 5).select()

This will produce a statement resembling:

SELECT EXISTS (SELECT id FROM some_table WHERE some_table = :param) AS anon_1
Parameters:
  • whereclause

    a WHERE clause, equivalent to calling the Select.where() method.

    Deprecated since version 1.4: The Exists.select().whereclause parameter is deprecated and will be removed in version 2.0. Please make use of the Select.where() method to add WHERE criteria to the SELECT statement.

  • **kwargs

    additional keyword arguments are passed to the legacy constructor for Select described at Select.create_legacy_select().

    Deprecated since version 1.4: The Exists.select() method will no longer accept keyword arguments in version 2.0. Please use generative methods from the Select construct in order to apply additional modifications.

See also

select() - general purpose method which allows for arbitrary column lists.

method sqlalchemy.sql.expression.Exists.select_from(*froms)

Return a new Exists construct, applying the given expression to the Select.select_from() method of the select statement contained.

Note

it is typically preferable to build a Select statement first, including the desired WHERE clause, then use the SelectBase.exists() method to produce an Exists object at once.

method sqlalchemy.sql.expression.Exists.where(*clause)

Return a new exists() construct with the given expression added to its WHERE clause, joined to the existing clause via AND, if any.

Note

it is typically preferable to build a Select statement first, including the desired WHERE clause, then use the SelectBase.exists() method to produce an Exists object at once.

class sqlalchemy.sql.expression.FromClause

Represent an element that can be used within the FROM clause of a SELECT statement.

The most common forms of FromClause are the Table and the select() constructs. Key features common to all FromClause objects include:

Class signature

class sqlalchemy.sql.expression.FromClause (sqlalchemy.sql.roles.AnonymizedFromClauseRole, sqlalchemy.sql.expression.Selectable)

method sqlalchemy.sql.expression.FromClause.alias(name=None, flat=False)

Return an alias of this FromClause.

E.g.:

a2 = some_table.alias('a2')

The above code creates an Alias object which can be used as a FROM clause in any SELECT statement.

attribute sqlalchemy.sql.expression.FromClause.c

A named-based collection of ColumnElement objects maintained by this FromClause.

The FromClause.c attribute is an alias for the FromClause.columns attribute.

Returns:

a ColumnCollection

attribute sqlalchemy.sql.expression.FromClause.columns

A named-based collection of ColumnElement objects maintained by this FromClause.

The columns, or c collection, is the gateway to the construction of SQL expressions using table-bound or other selectable-bound columns:

select(mytable).where(mytable.c.somecolumn == 5)
Returns:

a ColumnCollection object.

attribute sqlalchemy.sql.expression.FromClause.description

A brief description of this FromClause.

Used primarily for error message formatting.

attribute sqlalchemy.sql.expression.FromClause.entity_namespace

Return a namespace used for name-based access in SQL expressions.

This is the namespace that is used to resolve “filter_by()” type expressions, such as:

stmt.filter_by(address='some address')

It defaults to the .c collection, however internally it can be overridden using the “entity_namespace” annotation to deliver alternative results.

attribute sqlalchemy.sql.expression.FromClause.exported_columns

A ColumnCollection that represents the “exported” columns of this Selectable.

The “exported” columns for a FromClause object are synonymous with the FromClause.columns collection.

New in version 1.4.

attribute sqlalchemy.sql.expression.FromClause.foreign_keys

Return the collection of ForeignKey marker objects which this FromClause references.

Each ForeignKey is a member of a Table-wide ForeignKeyConstraint.

method sqlalchemy.sql.expression.FromClause.is_derived_from(fromclause)

Return True if this FromClause is ‘derived’ from the given FromClause.

An example would be an Alias of a Table is derived from that Table.

method sqlalchemy.sql.expression.FromClause.join(right, onclause=None, isouter=False, full=False)

Return a Join from this FromClause to another FromClause.

E.g.:

from sqlalchemy import join

j = user_table.join(address_table,
                user_table.c.id == address_table.c.user_id)
stmt = select(user_table).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id
Parameters:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.

  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.

  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.

  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN. Implies FromClause.join.isouter.

    New in version 1.1.

See also

join() - standalone function

Join - the type of object produced

method sqlalchemy.sql.expression.FromClause.outerjoin(right, onclause=None, full=False)

Return a Join from this FromClause to another FromClause, with the “isouter” flag set to True.

E.g.:

from sqlalchemy import outerjoin

j = user_table.outerjoin(address_table,
                user_table.c.id == address_table.c.user_id)

The above is equivalent to:

j = user_table.join(
    address_table,
    user_table.c.id == address_table.c.user_id,
    isouter=True)
Parameters:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.

  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.

  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN.

    New in version 1.1.

attribute sqlalchemy.sql.expression.FromClause.primary_key

Return the iterable collection of Column objects which comprise the primary key of this _selectable.FromClause.

For a Table object, this collection is represented by the PrimaryKeyConstraint which itself is an iterable collection of Column objects.

attribute sqlalchemy.sql.expression.FromClause.schema = None

Define the ‘schema’ attribute for this FromClause.

This is typically None for most objects except that of Table, where it is taken as the value of the Table.schema argument.

method sqlalchemy.sql.expression.FromClause.select(whereclause=None, **kwargs)

Return a SELECT of this FromClause.

e.g.:

stmt = some_table.select().where(some_table.c.id == 5)
Parameters:

See also

select() - general purpose method which allows for arbitrary column lists.

method sqlalchemy.sql.expression.FromClause.table_valued()

Return a TableValuedColumn object for this FromClause.

A TableValuedColumn is a ColumnElement that represents a complete row in a table. Support for this construct is backend dependent, and is supported in various forms by backends such as PostgreSQL, Oracle and SQL Server.

E.g.:

>>> from sqlalchemy import select, column, func, table
>>> a = table("a", column("id"), column("x"), column("y"))
>>> stmt = select(func.row_to_json(a.table_valued()))
>>> print(stmt)
SELECT row_to_json(a) AS row_to_json_1
FROM a

New in version 1.4.0b2.

method sqlalchemy.sql.expression.FromClause.tablesample(sampling, name=None, seed=None)

Return a TABLESAMPLE alias of this FromClause.

The return value is the TableSample construct also provided by the top-level tablesample() function.

New in version 1.1.

See also

tablesample() - usage guidelines and parameters

class sqlalchemy.sql.expression.GenerativeSelect(_label_style=symbol('LABEL_STYLE_DISAMBIGUATE_ONLY'), use_labels=False, limit=None, offset=None, order_by=None, group_by=None, bind=None)

Base class for SELECT statements where additional elements can be added.

This serves as the base for Select and CompoundSelect where elements such as ORDER BY, GROUP BY can be added and column rendering can be controlled. Compare to TextualSelect, which, while it subclasses SelectBase and is also a SELECT construct, represents a fixed textual string which cannot be altered at this level, only wrapped as a subquery.

Class signature

class sqlalchemy.sql.expression.GenerativeSelect (sqlalchemy.sql.expression.DeprecatedSelectBaseGenerations, sqlalchemy.sql.expression.SelectBase)

method sqlalchemy.sql.expression.GenerativeSelect.apply_labels()

Deprecated since version 1.4: The GenerativeSelect.apply_labels() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Use set_label_style(LABEL_STYLE_TABLENAME_PLUS_COL) instead. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

method sqlalchemy.sql.expression.GenerativeSelect.fetch(count, with_ties=False, percent=False)

Return a new selectable with the given FETCH FIRST criterion applied.

This is a numeric value which usually renders as FETCH {FIRST | NEXT} [ count ] {ROW | ROWS} {ONLY | WITH TIES} expression in the resulting select. This functionality is is currently implemented for Oracle, PostgreSQL, MSSQL.

Use GenerativeSelect.offset() to specify the offset.

Note

The GenerativeSelect.fetch() method will replace any clause applied with GenerativeSelect.limit().

New in version 1.4.

Parameters:
  • count – an integer COUNT parameter, or a SQL expression that provides an integer result. When percent=True this will represent the percentage of rows to return, not the absolute value. Pass None to reset it.

  • with_ties – When True, the WITH TIES option is used to return any additional rows that tie for the last place in the result set according to the ORDER BY clause. The ORDER BY may be mandatory in this case. Defaults to False

  • percent – When True, count represents the percentage of the total number of selected rows to return. Defaults to False

method sqlalchemy.sql.expression.GenerativeSelect.get_label_style()

Retrieve the current label style.

New in version 1.4.

method sqlalchemy.sql.expression.GenerativeSelect.group_by(*clauses)

Return a new selectable with the given list of GROUP BY criterion applied.

All existing GROUP BY settings can be suppressed by passing None.

e.g.:

stmt = select(table.c.name, func.max(table.c.stat)).\
group_by(table.c.name)
Parameters:

*clauses – a series of ColumnElement constructs which will be used to generate an GROUP BY clause.

method sqlalchemy.sql.expression.GenerativeSelect.limit(limit)

Return a new selectable with the given LIMIT criterion applied.

This is a numerical value which usually renders as a LIMIT expression in the resulting select. Backends that don’t support LIMIT will attempt to provide similar functionality.

Note

The GenerativeSelect.limit() method will replace any clause applied with GenerativeSelect.fetch().

Changed in version 1.0.0: - Select.limit() can now accept arbitrary SQL expressions as well as integer values.

Parameters:

limit – an integer LIMIT parameter, or a SQL expression that provides an integer result. Pass None to reset it.

method sqlalchemy.sql.expression.GenerativeSelect.offset(offset)

Return a new selectable with the given OFFSET criterion applied.

This is a numeric value which usually renders as an OFFSET expression in the resulting select. Backends that don’t support OFFSET will attempt to provide similar functionality.

Changed in version 1.0.0: - Select.offset() can now accept arbitrary SQL expressions as well as integer values.

Parameters:

offset – an integer OFFSET parameter, or a SQL expression that provides an integer result. Pass None to reset it.

method sqlalchemy.sql.expression.GenerativeSelect.order_by(*clauses)

Return a new selectable with the given list of ORDER BY criteria applied.

e.g.:

stmt = select(table).order_by(table.c.id, table.c.name)

Calling this method multiple times is equivalent to calling it once with all the clauses concatenated. All existing ORDER BY criteria may be cancelled by passing None by itself. New ORDER BY criteria may then be added by invoking Query.order_by() again, e.g.:

# will erase all ORDER BY and ORDER BY new_col alone
stmt = stmt.order_by(None).order_by(new_col)
Parameters:

*clauses – a series of ColumnElement constructs which will be used to generate an ORDER BY clause.

method sqlalchemy.sql.expression.GenerativeSelect.set_label_style(style)

Return a new selectable with the specified label style.

There are three “label styles” available, LABEL_STYLE_DISAMBIGUATE_ONLY, LABEL_STYLE_TABLENAME_PLUS_COL, and LABEL_STYLE_NONE. The default style is LABEL_STYLE_DISAMBIGUATE_ONLY.

In modern SQLAlchemy, there is not generally a need to change the labeling style, as per-expression labels are more effectively used by making use of the ColumnElement.label() method. In past versions, LABEL_STYLE_TABLENAME_PLUS_COL was used to disambiguate same-named columns from different tables, aliases, or subqueries; the newer LABEL_STYLE_DISAMBIGUATE_ONLY now applies labels only to names that conflict with an existing name so that the impact of this labeling is minimal.

The rationale for disambiguation is mostly so that all column expressions are available from a given FromClause.c collection when a subquery is created.

New in version 1.4: - the GenerativeSelect.set_label_style() method replaces the previous combination of .apply_labels(), .with_labels() and use_labels=True methods and/or parameters.

method sqlalchemy.sql.expression.GenerativeSelect.slice(start, stop)

Apply LIMIT / OFFSET to this statement based on a slice.

The start and stop indices behave like the argument to Python’s built-in range() function. This method provides an alternative to using LIMIT/OFFSET to get a slice of the query.

For example,

stmt = select(User).order_by(User.id).slice(1, 3)

renders as

SELECT users.id AS users_id,
       users.name AS users_name
FROM users ORDER BY users.id
LIMIT ? OFFSET ?
(2, 1)

Note

The GenerativeSelect.slice() method will replace any clause applied with GenerativeSelect.fetch().

New in version 1.4: Added the GenerativeSelect.slice() method generalized from the ORM.

method sqlalchemy.sql.expression.GenerativeSelect.with_for_update(nowait=False, read=False, of=None, skip_locked=False, key_share=False)

Specify a FOR UPDATE clause for this GenerativeSelect.

E.g.:

stmt = select(table).with_for_update(nowait=True)

On a database like PostgreSQL or Oracle, the above would render a statement like:

SELECT table.a, table.b FROM table FOR UPDATE NOWAIT

on other backends, the nowait option is ignored and instead would produce:

SELECT table.a, table.b FROM table FOR UPDATE

When called with no arguments, the statement will render with the suffix FOR UPDATE. Additional arguments can then be provided which allow for common database-specific variants.

Parameters:
  • nowait – boolean; will render FOR UPDATE NOWAIT on Oracle and PostgreSQL dialects.

  • read – boolean; will render LOCK IN SHARE MODE on MySQL, FOR SHARE on PostgreSQL. On PostgreSQL, when combined with nowait, will render FOR SHARE NOWAIT.

  • of – SQL expression or list of SQL expression elements (typically Column objects or a compatible expression) which will render into a FOR UPDATE OF clause; supported by PostgreSQL and Oracle. May render as a table or as a column depending on backend.

  • skip_locked – boolean, will render FOR UPDATE SKIP LOCKED on Oracle and PostgreSQL dialects or FOR SHARE SKIP LOCKED if read=True is also specified.

  • key_share – boolean, will render FOR NO KEY UPDATE, or if combined with read=True will render FOR KEY SHARE, on the PostgreSQL dialect.

class sqlalchemy.sql.expression.HasCTE

Mixin that declares a class to include CTE support.

New in version 1.1.

Members

add_cte(), cte()

Class signature

class sqlalchemy.sql.expression.HasCTE (sqlalchemy.sql.roles.HasCTERole)

method sqlalchemy.sql.expression.HasCTE.add_cte(cte)

Add a CTE to this statement object that will be independently rendered even if not referenced in the statement otherwise.

This feature is useful for the use case of embedding a DML statement such as an INSERT or UPDATE as a CTE inline with a primary statement that may draw from its results indirectly; while PostgreSQL is known to support this usage, it may not be supported by other backends.

E.g.:

from sqlalchemy import table, column, select
t = table('t', column('c1'), column('c2'))

ins = t.insert().values({"c1": "x", "c2": "y"}).cte()

stmt = select(t).add_cte(ins)

Would render:

WITH anon_1 AS
(INSERT INTO t (c1, c2) VALUES (:param_1, :param_2))
SELECT t.c1, t.c2
FROM t

Above, the “anon_1” CTE is not referred towards in the SELECT statement, however still accomplishes the task of running an INSERT statement.

Similarly in a DML-related context, using the PostgreSQL Insert construct to generate an “upsert”:

from sqlalchemy import table, column
from sqlalchemy.dialects.postgresql import insert

t = table("t", column("c1"), column("c2"))

delete_statement_cte = (
    t.delete().where(t.c.c1 < 1).cte("deletions")
)

insert_stmt = insert(t).values({"c1": 1, "c2": 2})
update_statement = insert_stmt.on_conflict_do_update(
    index_elements=[t.c.c1],
    set_={
        "c1": insert_stmt.excluded.c1,
        "c2": insert_stmt.excluded.c2,
    },
).add_cte(delete_statement_cte)

print(update_statement)

The above statement renders as:

WITH deletions AS
(DELETE FROM t WHERE t.c1 < %(c1_1)s)
INSERT INTO t (c1, c2) VALUES (%(c1)s, %(c2)s)
ON CONFLICT (c1) DO UPDATE SET c1 = excluded.c1, c2 = excluded.c2

New in version 1.4.21.

method sqlalchemy.sql.expression.HasCTE.cte(name=None, recursive=False, nesting=False)

Return a new CTE, or Common Table Expression instance.

Common table expressions are a SQL standard whereby SELECT statements can draw upon secondary statements specified along with the primary statement, using a clause called “WITH”. Special semantics regarding UNION can also be employed to allow “recursive” queries, where a SELECT statement can draw upon the set of rows that have previously been selected.

CTEs can also be applied to DML constructs UPDATE, INSERT and DELETE on some databases, both as a source of CTE rows when combined with RETURNING, as well as a consumer of CTE rows.

Changed in version 1.1: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.

SQLAlchemy detects CTE objects, which are treated similarly to Alias objects, as special elements to be delivered to the FROM clause of the statement as well as to a WITH clause at the top of the statement.

For special prefixes such as PostgreSQL “MATERIALIZED” and “NOT MATERIALIZED”, the CTE.prefix_with() method may be used to establish these.

Changed in version 1.3.13: Added support for prefixes. In particular - MATERIALIZED and NOT MATERIALIZED.

Parameters:
  • name – name given to the common table expression. Like FromClause.alias(), the name can be left as None in which case an anonymous symbol will be used at query compile time.

  • recursive – if True, will render WITH RECURSIVE. A recursive common table expression is intended to be used in conjunction with UNION ALL in order to derive rows from those already selected.

  • nesting

    if True, will render the CTE locally to the actual statement.

    New in version 1.4.24.

The following examples include two from PostgreSQL’s documentation at https://www.postgresql.org/docs/current/static/queries-with.html, as well as additional examples.

Example 1, non recursive:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

orders = Table('orders', metadata,
    Column('region', String),
    Column('amount', Integer),
    Column('product', String),
    Column('quantity', Integer)
)

regional_sales = select(
                    orders.c.region,
                    func.sum(orders.c.amount).label('total_sales')
                ).group_by(orders.c.region).cte("regional_sales")


top_regions = select(regional_sales.c.region).\
        where(
            regional_sales.c.total_sales >
            select(
                func.sum(regional_sales.c.total_sales) / 10
            )
        ).cte("top_regions")

statement = select(
            orders.c.region,
            orders.c.product,
            func.sum(orders.c.quantity).label("product_units"),
            func.sum(orders.c.amount).label("product_sales")
    ).where(orders.c.region.in_(
        select(top_regions.c.region)
    )).group_by(orders.c.region, orders.c.product)

result = conn.execute(statement).fetchall()

Example 2, WITH RECURSIVE:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

parts = Table('parts', metadata,
    Column('part', String),
    Column('sub_part', String),
    Column('quantity', Integer),
)

included_parts = select(\
    parts.c.sub_part, parts.c.part, parts.c.quantity\
    ).\
    where(parts.c.part=='our part').\
    cte(recursive=True)


incl_alias = included_parts.alias()
parts_alias = parts.alias()
included_parts = included_parts.union_all(
    select(
        parts_alias.c.sub_part,
        parts_alias.c.part,
        parts_alias.c.quantity
    ).\
    where(parts_alias.c.part==incl_alias.c.sub_part)
)

statement = select(
            included_parts.c.sub_part,
            func.sum(included_parts.c.quantity).
              label('total_quantity')
        ).\
        group_by(included_parts.c.sub_part)

result = conn.execute(statement).fetchall()

Example 3, an upsert using UPDATE and INSERT with CTEs:

from datetime import date
from sqlalchemy import (MetaData, Table, Column, Integer,
                        Date, select, literal, and_, exists)

metadata = MetaData()

visitors = Table('visitors', metadata,
    Column('product_id', Integer, primary_key=True),
    Column('date', Date, primary_key=True),
    Column('count', Integer),
)

# add 5 visitors for the product_id == 1
product_id = 1
day = date.today()
count = 5

update_cte = (
    visitors.update()
    .where(and_(visitors.c.product_id == product_id,
                visitors.c.date == day))
    .values(count=visitors.c.count + count)
    .returning(literal(1))
    .cte('update_cte')
)

upsert = visitors.insert().from_select(
    [visitors.c.product_id, visitors.c.date, visitors.c.count],
    select(literal(product_id), literal(day), literal(count))
        .where(~exists(update_cte.select()))
)

connection.execute(upsert)

Example 4, Nesting CTE (SQLAlchemy 1.4.24 and above):

value_a = select(
    literal("root").label("n")
).cte("value_a")

# A nested CTE with the same name as the root one
value_a_nested = select(
    literal("nesting").label("n")
).cte("value_a", nesting=True)

# Nesting CTEs takes ascendency locally
# over the CTEs at a higher level
value_b = select(value_a_nested.c.n).cte("value_b")

value_ab = select(value_a.c.n.label("a"), value_b.c.n.label("b"))

The above query will render the second CTE nested inside the first, shown with inline parameters below as:

WITH
    value_a AS
        (SELECT 'root' AS n),
    value_b AS
        (WITH value_a AS
            (SELECT 'nesting' AS n)
        SELECT value_a.n AS n FROM value_a)
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

See also

Query.cte() - ORM version of HasCTE.cte().

class sqlalchemy.sql.expression.HasPrefixes

Members

prefix_with()

method sqlalchemy.sql.expression.HasPrefixes.prefix_with(*expr, **kw)

Add one or more expressions following the statement keyword, i.e. SELECT, INSERT, UPDATE, or DELETE. Generative.

This is used to support backend-specific prefix keywords such as those provided by MySQL.

E.g.:

stmt = table.insert().prefix_with("LOW_PRIORITY", dialect="mysql")

# MySQL 5.7 optimizer hints
stmt = select(table).prefix_with(
    "/*+ BKA(t1) */", dialect="mysql")

Multiple prefixes can be specified by multiple calls to HasPrefixes.prefix_with().

Parameters:
  • *expr – textual or ClauseElement construct which will be rendered following the INSERT, UPDATE, or DELETE keyword.

  • **kw – A single keyword ‘dialect’ is accepted. This is an optional string dialect name which will limit rendering of this prefix to only that dialect.

class sqlalchemy.sql.expression.HasSuffixes

Members

suffix_with()

method sqlalchemy.sql.expression.HasSuffixes.suffix_with(*expr, **kw)

Add one or more expressions following the statement as a whole.

This is used to support backend-specific suffix keywords on certain constructs.

E.g.:

stmt = select(col1, col2).cte().suffix_with(
    "cycle empno set y_cycle to 1 default 0", dialect="oracle")

Multiple suffixes can be specified by multiple calls to HasSuffixes.suffix_with().

Parameters:
  • *expr – textual or ClauseElement construct which will be rendered following the target clause.

  • **kw – A single keyword ‘dialect’ is accepted. This is an optional string dialect name which will limit rendering of this suffix to only that dialect.

class sqlalchemy.sql.expression.Join(left, right, onclause=None, isouter=False, full=False)

Represent a JOIN construct between two FromClause elements.

The public constructor function for Join is the module-level join() function, as well as the FromClause.join() method of any FromClause (e.g. such as Table).

Class signature

class sqlalchemy.sql.expression.Join (sqlalchemy.sql.roles.DMLTableRole, sqlalchemy.sql.expression.FromClause)

method sqlalchemy.sql.expression.Join.__init__(left, right, onclause=None, isouter=False, full=False)

Construct a new Join.

The usual entrypoint here is the join() function or the FromClause.join() method of any FromClause object.

method sqlalchemy.sql.expression.Join.alias(name=None, flat=False)

Return an alias of this Join.

Deprecated since version 1.4: The Join.alias() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Create a select + subquery, or alias the individual tables inside the join, instead. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

The default behavior here is to first produce a SELECT construct from this Join, then to produce an Alias from that. So given a join of the form:

j = table_a.join(table_b, table_a.c.id == table_b.c.a_id)

The JOIN by itself would look like:

table_a JOIN table_b ON table_a.id = table_b.a_id

Whereas the alias of the above, j.alias(), would in a SELECT context look like:

(SELECT table_a.id AS table_a_id, table_b.id AS table_b_id,
    table_b.a_id AS table_b_a_id
    FROM table_a
    JOIN table_b ON table_a.id = table_b.a_id) AS anon_1

The equivalent long-hand form, given a Join object j, is:

from sqlalchemy import select, alias
j = alias(
    select(j.left, j.right).\
        select_from(j).\
        set_label_style(LABEL_STYLE_TABLENAME_PLUS_COL).\
        correlate(False),
    name=name
)

The selectable produced by Join.alias() features the same columns as that of the two individual selectables presented under a single name - the individual columns are “auto-labeled”, meaning the .c. collection of the resulting Alias represents the names of the individual columns using a <tablename>_<columname> scheme:

j.c.table_a_id
j.c.table_b_a_id

Join.alias() also features an alternate option for aliasing joins which produces no enclosing SELECT and does not normally apply labels to the column names. The flat=True option will call FromClause.alias() against the left and right sides individually. Using this option, no new SELECT is produced; we instead, from a construct as below:

j = table_a.join(table_b, table_a.c.id == table_b.c.a_id)
j = j.alias(flat=True)

we get a result like this:

table_a AS table_a_1 JOIN table_b AS table_b_1 ON
table_a_1.id = table_b_1.a_id

The flat=True argument is also propagated to the contained selectables, so that a composite join such as:

j = table_a.join(
        table_b.join(table_c,
                table_b.c.id == table_c.c.b_id),
        table_b.c.a_id == table_a.c.id
    ).alias(flat=True)

Will produce an expression like:

table_a AS table_a_1 JOIN (
        table_b AS table_b_1 JOIN table_c AS table_c_1
        ON table_b_1.id = table_c_1.b_id
) ON table_a_1.id = table_b_1.a_id

The standalone alias() function as well as the base FromClause.alias() method also support the flat=True argument as a no-op, so that the argument can be passed to the alias() method of any selectable.

Parameters:
  • name – name given to the alias.

  • flat – if True, produce an alias of the left and right sides of this Join and return the join of those two selectables. This produces join expression that does not include an enclosing SELECT.

attribute sqlalchemy.sql.expression.Join.bind

Return the bound engine associated with either the left or right side of this Join.

Deprecated since version 1.4: The Executable.bind attribute is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Bound metadata is being removed as of SQLAlchemy 2.0. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

attribute sqlalchemy.sql.expression.Join.description
method sqlalchemy.sql.expression.Join.is_derived_from(fromclause)

Return True if this FromClause is ‘derived’ from the given FromClause.

An example would be an Alias of a Table is derived from that Table.

method sqlalchemy.sql.expression.Join.select(whereclause=None, **kwargs)

Create a Select from this Join.

E.g.:

stmt = table_a.join(table_b, table_a.c.id == table_b.c.a_id)

stmt = stmt.select()

The above will produce a SQL string resembling:

SELECT table_a.id, table_a.col, table_b.id, table_b.a_id
FROM table_a JOIN table_b ON table_a.id = table_b.a_id
Parameters:
method sqlalchemy.sql.expression.Join.self_group(against=None)

Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a “grouping” construct, i.e. parenthesis. In particular it’s used by “binary” expressions to provide a grouping around themselves when placed into a larger expression, as well as by select() constructs when placed into the FROM clause of another select(). (Note that subqueries should be normally created using the Select.alias() method, as many platforms require nested SELECT statements to be named).

As expressions are composed together, the application of self_group() is automatic - end-user code should never need to use this method directly. Note that SQLAlchemy’s clause constructs take operator precedence into account - so parenthesis might not be needed, for example, in an expression like x OR (y AND z) - AND takes precedence over OR.

The base self_group() method of ClauseElement just returns self.

class sqlalchemy.sql.expression.Lateral(*arg, **kw)

Represent a LATERAL subquery.

This object is constructed from the lateral() module level function as well as the FromClause.lateral() method available on all FromClause subclasses.

While LATERAL is part of the SQL standard, currently only more recent PostgreSQL versions provide support for this keyword.

New in version 1.1.

See also

LATERAL correlation - overview of usage.

Members

inherit_cache

attribute sqlalchemy.sql.expression.Lateral.inherit_cache = True

Indicate if this HasCacheKey instance should make use of the cache key generation scheme used by its immediate superclass.

The attribute defaults to None, which indicates that a construct has not yet taken into account whether or not its appropriate for it to participate in caching; this is functionally equivalent to setting the value to False, except that a warning is also emitted.

This flag can be set to True on a particular class, if the SQL that corresponds to the object does not change based on attributes which are local to this class, and not its superclass.

See also

Enabling Caching Support for Custom Constructs - General guideslines for setting the HasCacheKey.inherit_cache attribute for third-party or user defined SQL constructs.

class sqlalchemy.sql.expression.ReturnsRows

The base-most class for Core constructs that have some concept of columns that can represent rows.

While the SELECT statement and TABLE are the primary things we think of in this category, DML like INSERT, UPDATE and DELETE can also specify RETURNING which means they can be used in CTEs and other forms, and PostgreSQL has functions that return rows also.

New in version 1.4.

Class signature

class sqlalchemy.sql.expression.ReturnsRows (sqlalchemy.sql.roles.ReturnsRowsRole, sqlalchemy.sql.expression.ClauseElement)

attribute sqlalchemy.sql.expression.ReturnsRows.exported_columns

A ColumnCollection that represents the “exported” columns of this ReturnsRows.

The “exported” columns represent the collection of ColumnElement expressions that are rendered by this SQL construct. There are primary varieties which are the “FROM clause columns” of a FROM clause, such as a table, join, or subquery, the “SELECTed columns”, which are the columns in the “columns clause” of a SELECT statement, and the RETURNING columns in a DML statement..

New in version 1.4.

class sqlalchemy.sql.expression.ScalarSelect(element)

Represent a scalar subquery.

A ScalarSelect is created by invoking the SelectBase.scalar_subquery() method. The object then participates in other SQL expressions as a SQL column expression within the ColumnElement hierarchy.

Class signature

class sqlalchemy.sql.expression.ScalarSelect (sqlalchemy.sql.roles.InElementRole, sqlalchemy.sql.expression.Generative, sqlalchemy.sql.expression.Grouping)

method sqlalchemy.sql.expression.ScalarSelect.correlate(*fromclauses)

Return a new ScalarSelect which will correlate the given FROM clauses to that of an enclosing Select.

This method is mirrored from the Select.correlate() method of the underlying Select. The method applies the :meth:_sql.Select.correlate` method, then returns a new ScalarSelect against that statement.

New in version 1.4: Previously, the ScalarSelect.correlate() method was only available from Select.

Parameters:

*fromclauses – a list of one or more FromClause constructs, or other compatible constructs (i.e. ORM-mapped classes) to become part of the correlate collection.

method sqlalchemy.sql.expression.ScalarSelect.correlate_except(*fromclauses)

Return a new ScalarSelect which will omit the given FROM clauses from the auto-correlation process.

This method is mirrored from the Select.correlate_except() method of the underlying Select. The method applies the :meth:_sql.Select.correlate_except` method, then returns a new ScalarSelect against that statement.

New in version 1.4: Previously, the ScalarSelect.correlate_except() method was only available from Select.

Parameters:

*fromclauses – a list of one or more FromClause constructs, or other compatible constructs (i.e. ORM-mapped classes) to become part of the correlate-exception collection.

attribute sqlalchemy.sql.expression.ScalarSelect.inherit_cache = True

Indicate if this HasCacheKey instance should make use of the cache key generation scheme used by its immediate superclass.

The attribute defaults to None, which indicates that a construct has not yet taken into account whether or not its appropriate for it to participate in caching; this is functionally equivalent to setting the value to False, except that a warning is also emitted.

This flag can be set to True on a particular class, if the SQL that corresponds to the object does not change based on attributes which are local to this class, and not its superclass.

See also

Enabling Caching Support for Custom Constructs - General guideslines for setting the HasCacheKey.inherit_cache attribute for third-party or user defined SQL constructs.

method sqlalchemy.sql.expression.ScalarSelect.self_group(**kwargs)

Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a “grouping” construct, i.e. parenthesis. In particular it’s used by “binary” expressions to provide a grouping around themselves when placed into a larger expression, as well as by select() constructs when placed into the FROM clause of another select(). (Note that subqueries should be normally created using the Select.alias() method, as many platforms require nested SELECT statements to be named).

As expressions are composed together, the application of self_group() is automatic - end-user code should never need to use this method directly. Note that SQLAlchemy’s clause constructs take operator precedence into account - so parenthesis might not be needed, for example, in an expression like x OR (y AND z) - AND takes precedence over OR.

The base self_group() method of ClauseElement just returns self.

method sqlalchemy.sql.expression.ScalarSelect.where(crit)

Apply a WHERE clause to the SELECT statement referred to by this ScalarSelect.

class sqlalchemy.sql.expression.Select

Represents a SELECT statement.

The Select object is normally constructed using the select() function. See that function for details.

See also

select()

Selecting Rows with Core or ORM - in the 2.0 tutorial

Class signature

class sqlalchemy.sql.expression.Select (sqlalchemy.sql.expression.HasPrefixes, sqlalchemy.sql.expression.HasSuffixes, sqlalchemy.sql.expression.HasHints, sqlalchemy.sql.expression.HasCompileState, sqlalchemy.sql.expression.DeprecatedSelectGenerations, sqlalchemy.sql.expression._SelectFromElements, sqlalchemy.sql.expression.GenerativeSelect)

method sqlalchemy.sql.expression.Select.add_columns(*columns)

Return a new select() construct with the given column expressions added to its columns clause.

E.g.:

my_select = my_select.add_columns(table.c.new_column)

See the documentation for Select.with_only_columns() for guidelines on adding /replacing the columns of a Select object.

method sqlalchemy.sql.expression.Select.add_cte(cte)

inherited from the HasCTE.add_cte() method of HasCTE

Add a CTE to this statement object that will be independently rendered even if not referenced in the statement otherwise.

This feature is useful for the use case of embedding a DML statement such as an INSERT or UPDATE as a CTE inline with a primary statement that may draw from its results indirectly; while PostgreSQL is known to support this usage, it may not be supported by other backends.

E.g.:

from sqlalchemy import table, column, select
t = table('t', column('c1'), column('c2'))

ins = t.insert().values({"c1": "x", "c2": "y"}).cte()

stmt = select(t).add_cte(ins)

Would render:

WITH anon_1 AS
(INSERT INTO t (c1, c2) VALUES (:param_1, :param_2))
SELECT t.c1, t.c2
FROM t

Above, the “anon_1” CTE is not referred towards in the SELECT statement, however still accomplishes the task of running an INSERT statement.

Similarly in a DML-related context, using the PostgreSQL Insert construct to generate an “upsert”:

from sqlalchemy import table, column
from sqlalchemy.dialects.postgresql import insert

t = table("t", column("c1"), column("c2"))

delete_statement_cte = (
    t.delete().where(t.c.c1 < 1).cte("deletions")
)

insert_stmt = insert(t).values({"c1": 1, "c2": 2})
update_statement = insert_stmt.on_conflict_do_update(
    index_elements=[t.c.c1],
    set_={
        "c1": insert_stmt.excluded.c1,
        "c2": insert_stmt.excluded.c2,
    },
).add_cte(delete_statement_cte)

print(update_statement)

The above statement renders as:

WITH deletions AS
(DELETE FROM t WHERE t.c1 < %(c1_1)s)
INSERT INTO t (c1, c2) VALUES (%(c1)s, %(c2)s)
ON CONFLICT (c1) DO UPDATE SET c1 = excluded.c1, c2 = excluded.c2

New in version 1.4.21.

method sqlalchemy.sql.expression.Select.alias(name=None, flat=False)

inherited from the SelectBase.alias() method of SelectBase

Return a named subquery against this SelectBase.

For a SelectBase (as opposed to a FromClause), this returns a Subquery object which behaves mostly the same as the Alias object that is used with a FromClause.

Changed in version 1.4: The SelectBase.alias() method is now a synonym for the SelectBase.subquery() method.

method sqlalchemy.sql.expression.Select.apply_labels()

inherited from the GenerativeSelect.apply_labels() method of GenerativeSelect

Deprecated since version 1.4: The GenerativeSelect.apply_labels() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Use set_label_style(LABEL_STYLE_TABLENAME_PLUS_COL) instead. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

method sqlalchemy.sql.expression.Select.as_scalar()

inherited from the SelectBase.as_scalar() method of SelectBase

Deprecated since version 1.4: The SelectBase.as_scalar() method is deprecated and will be removed in a future release. Please refer to SelectBase.scalar_subquery().

attribute sqlalchemy.sql.expression.Select.bind

Returns the Engine or Connection to which this Executable is bound, or None if none found.

Deprecated since version 1.4: The Executable.bind attribute is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Bound metadata is being removed as of SQLAlchemy 2.0. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

attribute sqlalchemy.sql.expression.Select.c

inherited from the SelectBase.c attribute of SelectBase

Deprecated since version 1.4: The SelectBase.c and SelectBase.columns attributes are deprecated and will be removed in a future release; these attributes implicitly create a subquery that should be explicit. Please call SelectBase.subquery() first in order to create a subquery, which then contains this attribute. To access the columns that this SELECT object SELECTs from, use the SelectBase.selected_columns attribute.

method sqlalchemy.sql.expression.Select.column(column)

Return a new select() construct with the given column expression added to its columns clause.

Deprecated since version 1.4: The Select.column() method is deprecated and will be removed in a future release. Please use Select.add_columns()

E.g.:

my_select = my_select.column(table.c.new_column)

See the documentation for Select.with_only_columns() for guidelines on adding /replacing the columns of a Select object.

attribute sqlalchemy.sql.expression.Select.column_descriptions

Return a plugin-enabled ‘column descriptions’ structure referring to the columns which are SELECTed by this statement.

This attribute is generally useful when using the ORM, as an extended structure which includes information about mapped entities is returned. The section Inspecting entities and columns from ORM-enabled SELECT and DML statements contains more background.

For a Core-only statement, the structure returned by this accessor is derived from the same objects that are returned by the Select.selected_columns accessor, formatted as a list of dictionaries which contain the keys name, type and expr, which indicate the column expressions to be selected:

>>> stmt = select(user_table)
>>> stmt.column_descriptions
[
    {
        'name': 'id',
        'type': Integer(),
        'expr': Column('id', Integer(), ...)},
    {
        'name': 'name',
        'type': String(length=30),
        'expr': Column('name', String(length=30), ...)}
]

Changed in version 1.4.33: The Select.column_descriptions attribute returns a structure for a Core-only set of entities, not just ORM-only entities.

attribute sqlalchemy.sql.expression.Select.columns_clause_froms

Return the set of FromClause objects implied by the columns clause of this SELECT statement.

New in version 1.4.23.

See also

Select.froms - “final” FROM list taking the full statement into account

Select.with_only_columns() - makes use of this collection to set up a new FROM list

method sqlalchemy.sql.expression.Select.correlate(*fromclauses)

Return a new Select which will correlate the given FROM clauses to that of an enclosing Select.

Calling this method turns off the Select object’s default behavior of “auto-correlation”. Normally, FROM elements which appear in a Select that encloses this one via its WHERE clause, ORDER BY, HAVING or columns clause will be omitted from this Select object’s FROM clause. Setting an explicit correlation collection using the Select.correlate() method provides a fixed list of FROM objects that can potentially take place in this process.

When Select.correlate() is used to apply specific FROM clauses for correlation, the FROM elements become candidates for correlation regardless of how deeply nested this Select object is, relative to an enclosing 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 Select. Multi-level correlation ensures that the link between enclosed and enclosing 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 Select object will correlate none of its FROM entries, and all will render unconditionally in the local FROM clause.

Parameters:

*fromclauses – a list of one or more FromClause constructs, or other compatible constructs (i.e. ORM-mapped classes) to become part of the correlate collection.

method sqlalchemy.sql.expression.Select.correlate_except(*fromclauses)

Return a new Select which will omit the given FROM clauses from the auto-correlation process.

Calling Select.correlate_except() turns off the 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.

If None is passed, the Select object will correlate all of its FROM entries.

Parameters:

*fromclauses – a list of one or more FromClause constructs, or other compatible constructs (i.e. ORM-mapped classes) to become part of the correlate-exception collection.

method sqlalchemy.sql.expression.Select.corresponding_column(column, require_embedded=False)

inherited from the Selectable.corresponding_column() method of Selectable

Given a ColumnElement, return the exported ColumnElement object from the Selectable.exported_columns collection of this Selectable which corresponds to that original ColumnElement via a common ancestor column.

Parameters:
  • column – the target ColumnElement to be matched.

  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this Selectable. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this Selectable.

See also

Selectable.exported_columns - the ColumnCollection that is used for the operation.

ColumnCollection.corresponding_column() - implementation method.

classmethod sqlalchemy.sql.expression.Select.create_legacy_select(columns=None, whereclause=None, from_obj=None, distinct=False, having=None, correlate=True, prefixes=None, suffixes=None, **kwargs)

Construct a new Select using the 1.x style API.

Deprecated since version 1.4: The legacy calling style of select() is deprecated and will be removed in SQLAlchemy 2.0. Please use the new calling style described at select(). (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

This method is called implicitly when the select() construct is used and the first argument is a Python list or other plain sequence object, which is taken to refer to the columns collection.

Changed in version 1.4: Added the Select.create_legacy_select() constructor which documents the calling style in use when the select() construct is invoked using 1.x-style arguments.

Similar functionality is also available via the FromClause.select() method on any FromClause.

All arguments which accept ClauseElement arguments also accept string arguments, which will be converted as appropriate into either text() or literal_column() constructs.

Parameters:
  • columns

    A list of ColumnElement or FromClause objects which will form the columns clause of the resulting statement. For those objects that are instances of FromClause (typically Table or Alias objects), the FromClause.c collection is extracted to form a collection of ColumnElement objects.

    This parameter will also accept TextClause constructs as given, as well as ORM-mapped classes.

    Note

    The select.columns parameter is not available in the method form of select(), e.g. FromClause.select().

  • whereclause

    A ClauseElement expression which will be used to form the WHERE clause. It is typically preferable to add WHERE criterion to an existing Select using method chaining with Select.where().

    See also

    Select.where()

  • from_obj

    A list of ClauseElement objects which will be added to the FROM clause of the resulting statement. This is equivalent to calling Select.select_from() using method chaining on an existing Select object.

    See also

    Select.select_from() - full description of explicit FROM clause specification.

  • bind=None – an Engine or Connection instance to which the resulting Select object will be bound. The Select object will otherwise automatically bind to whatever Connectable instances can be located within its contained ClauseElement members.

  • correlate=True

    indicates that this Select object should have its contained FromClause elements “correlated” to an enclosing Select object. It is typically preferable to specify correlations on an existing Select construct using Select.correlate().

    See also

    Select.correlate() - full description of correlation.

  • distinct=False

    when True, applies a DISTINCT qualifier to the columns clause of the resulting statement.

    The boolean argument may also be a column expression or list of column expressions - this is a special calling form which is understood by the PostgreSQL dialect to render the DISTINCT ON (<columns>) syntax.

    distinct is also available on an existing Select object via the Select.distinct() method.

  • group_by

    a list of ClauseElement objects which will comprise the GROUP BY clause of the resulting select. This parameter is typically specified more naturally using the Select.group_by() method on an existing Select.

  • having

    a ClauseElement that will comprise the HAVING clause of the resulting select when GROUP BY is used. This parameter is typically specified more naturally using the Select.having() method on an existing Select.

    See also

    Select.having()

  • limit=None

    a numerical value which usually renders as a LIMIT expression in the resulting select. Backends that don’t support LIMIT will attempt to provide similar functionality. This parameter is typically specified more naturally using the Select.limit() method on an existing Select.

    See also

    Select.limit()

  • offset=None

    a numeric value which usually renders as an OFFSET expression in the resulting select. Backends that don’t support OFFSET will attempt to provide similar functionality. This parameter is typically specified more naturally using the Select.offset() method on an existing Select.

    See also

    Select.offset()

  • order_by

    a scalar or list of ClauseElement objects which will comprise the ORDER BY clause of the resulting select. This parameter is typically specified more naturally using the Select.order_by() method on an existing Select.

  • use_labels=False

    when True, the statement will be generated using labels for each column in the columns clause, which qualify each column with its parent table’s (or aliases) name so that name conflicts between columns in different tables don’t occur. The format of the label is <tablename>_<column>. The “c” collection of a Subquery created against this Select object, as well as the Select.selected_columns collection of the Select itself, will use these names for targeting column members.

    This parameter can also be specified on an existing Select object using the Select.set_label_style() method.

method sqlalchemy.sql.expression.Select.cte(name=None, recursive=False, nesting=False)

inherited from the HasCTE.cte() method of HasCTE

Return a new CTE, or Common Table Expression instance.

Common table expressions are a SQL standard whereby SELECT statements can draw upon secondary statements specified along with the primary statement, using a clause called “WITH”. Special semantics regarding UNION can also be employed to allow “recursive” queries, where a SELECT statement can draw upon the set of rows that have previously been selected.

CTEs can also be applied to DML constructs UPDATE, INSERT and DELETE on some databases, both as a source of CTE rows when combined with RETURNING, as well as a consumer of CTE rows.

Changed in version 1.1: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.

SQLAlchemy detects CTE objects, which are treated similarly to Alias objects, as special elements to be delivered to the FROM clause of the statement as well as to a WITH clause at the top of the statement.

For special prefixes such as PostgreSQL “MATERIALIZED” and “NOT MATERIALIZED”, the CTE.prefix_with() method may be used to establish these.

Changed in version 1.3.13: Added support for prefixes. In particular - MATERIALIZED and NOT MATERIALIZED.

Parameters:
  • name – name given to the common table expression. Like FromClause.alias(), the name can be left as None in which case an anonymous symbol will be used at query compile time.

  • recursive – if True, will render WITH RECURSIVE. A recursive common table expression is intended to be used in conjunction with UNION ALL in order to derive rows from those already selected.

  • nesting

    if True, will render the CTE locally to the actual statement.

    New in version 1.4.24.

The following examples include two from PostgreSQL’s documentation at https://www.postgresql.org/docs/current/static/queries-with.html, as well as additional examples.

Example 1, non recursive:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

orders = Table('orders', metadata,
    Column('region', String),
    Column('amount', Integer),
    Column('product', String),
    Column('quantity', Integer)
)

regional_sales = select(
                    orders.c.region,
                    func.sum(orders.c.amount).label('total_sales')
                ).group_by(orders.c.region).cte("regional_sales")


top_regions = select(regional_sales.c.region).\
        where(
            regional_sales.c.total_sales >
            select(
                func.sum(regional_sales.c.total_sales) / 10
            )
        ).cte("top_regions")

statement = select(
            orders.c.region,
            orders.c.product,
            func.sum(orders.c.quantity).label("product_units"),
            func.sum(orders.c.amount).label("product_sales")
    ).where(orders.c.region.in_(
        select(top_regions.c.region)
    )).group_by(orders.c.region, orders.c.product)

result = conn.execute(statement).fetchall()

Example 2, WITH RECURSIVE:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

parts = Table('parts', metadata,
    Column('part', String),
    Column('sub_part', String),
    Column('quantity', Integer),
)

included_parts = select(\
    parts.c.sub_part, parts.c.part, parts.c.quantity\
    ).\
    where(parts.c.part=='our part').\
    cte(recursive=True)


incl_alias = included_parts.alias()
parts_alias = parts.alias()
included_parts = included_parts.union_all(
    select(
        parts_alias.c.sub_part,
        parts_alias.c.part,
        parts_alias.c.quantity
    ).\
    where(parts_alias.c.part==incl_alias.c.sub_part)
)

statement = select(
            included_parts.c.sub_part,
            func.sum(included_parts.c.quantity).
              label('total_quantity')
        ).\
        group_by(included_parts.c.sub_part)

result = conn.execute(statement).fetchall()

Example 3, an upsert using UPDATE and INSERT with CTEs:

from datetime import date
from sqlalchemy import (MetaData, Table, Column, Integer,
                        Date, select, literal, and_, exists)

metadata = MetaData()

visitors = Table('visitors', metadata,
    Column('product_id', Integer, primary_key=True),
    Column('date', Date, primary_key=True),
    Column('count', Integer),
)

# add 5 visitors for the product_id == 1
product_id = 1
day = date.today()
count = 5

update_cte = (
    visitors.update()
    .where(and_(visitors.c.product_id == product_id,
                visitors.c.date == day))
    .values(count=visitors.c.count + count)
    .returning(literal(1))
    .cte('update_cte')
)

upsert = visitors.insert().from_select(
    [visitors.c.product_id, visitors.c.date, visitors.c.count],
    select(literal(product_id), literal(day), literal(count))
        .where(~exists(update_cte.select()))
)

connection.execute(upsert)

Example 4, Nesting CTE (SQLAlchemy 1.4.24 and above):

value_a = select(
    literal("root").label("n")
).cte("value_a")

# A nested CTE with the same name as the root one
value_a_nested = select(
    literal("nesting").label("n")
).cte("value_a", nesting=True)

# Nesting CTEs takes ascendency locally
# over the CTEs at a higher level
value_b = select(value_a_nested.c.n).cte("value_b")

value_ab = select(value_a.c.n.label("a"), value_b.c.n.label("b"))

The above query will render the second CTE nested inside the first, shown with inline parameters below as:

WITH
    value_a AS
        (SELECT 'root' AS n),
    value_b AS
        (WITH value_a AS
            (SELECT 'nesting' AS n)
        SELECT value_a.n AS n FROM value_a)
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

See also

Query.cte() - ORM version of HasCTE.cte().

method sqlalchemy.sql.expression.Select.distinct(*expr)

Return a new select() construct which will apply DISTINCT to its columns clause.

Parameters:

*expr

optional column expressions. When present, the PostgreSQL dialect will render a DISTINCT ON (<expressions>>) construct.

Deprecated since version 1.4: Using *expr in other dialects is deprecated and will raise CompileError in a future version.

method sqlalchemy.sql.expression.Select.except_(*other, **kwargs)

Return a SQL EXCEPT of this select() construct against the given selectable provided as positional arguments.

Parameters:
  • *other

    one or more elements with which to create a UNION.

    Changed in version 1.4.28: multiple elements are now accepted.

  • **kwargs – keyword arguments are forwarded to the constructor for the newly created CompoundSelect object.

method sqlalchemy.sql.expression.Select.except_all(*other, **kwargs)

Return a SQL EXCEPT ALL of this select() construct against the given selectables provided as positional arguments.

Parameters:
  • *other

    one or more elements with which to create a UNION.

    Changed in version 1.4.28: multiple elements are now accepted.

  • **kwargs – keyword arguments are forwarded to the constructor for the newly created CompoundSelect object.

method sqlalchemy.sql.expression.Select.execute(*multiparams, **params)

inherited from the Executable.execute() method of Executable

Compile and execute this Executable.

Deprecated since version 1.4: The Executable.execute() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. All statement execution in SQLAlchemy 2.0 is performed by the Connection.execute() method of Connection, or in the ORM by the Session.execute() method of Session. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

method sqlalchemy.sql.expression.Select.execution_options(**kw)

inherited from the Executable.execution_options() method of Executable

Set non-SQL options for the statement which take effect during execution.

Execution options can be set on a per-statement or per Connection basis. Additionally, the Engine and ORM Query objects provide access to execution options which they in turn configure upon connections.

The execution_options() method is generative. A new instance of this statement is returned that contains the options:

statement = select(table.c.x, table.c.y)
statement = statement.execution_options(autocommit=True)

Note that only a subset of possible execution options can be applied to a statement - these include “autocommit” and “stream_results”, but not “isolation_level” or “compiled_cache”. See Connection.execution_options() for a full list of possible options.

method sqlalchemy.sql.expression.Select.exists()

inherited from the SelectBase.exists() method of SelectBase

Return an Exists representation of this selectable, which can be used as a column expression.

The returned object is an instance of Exists.

See also

exists()

EXISTS subqueries - in the 2.0 style tutorial.

New in version 1.4.

attribute sqlalchemy.sql.expression.Select.exported_columns

inherited from the SelectBase.exported_columns attribute of SelectBase

A ColumnCollection that represents the “exported” columns of this Selectable, not including TextClause constructs.

The “exported” columns for a SelectBase object are synonymous with the SelectBase.selected_columns collection.

New in version 1.4.

method sqlalchemy.sql.expression.Select.fetch(count, with_ties=False, percent=False)

inherited from the GenerativeSelect.fetch() method of GenerativeSelect

Return a new selectable with the given FETCH FIRST criterion applied.

This is a numeric value which usually renders as FETCH {FIRST | NEXT} [ count ] {ROW | ROWS} {ONLY | WITH TIES} expression in the resulting select. This functionality is is currently implemented for Oracle, PostgreSQL, MSSQL.

Use GenerativeSelect.offset() to specify the offset.

Note

The GenerativeSelect.fetch() method will replace any clause applied with GenerativeSelect.limit().

New in version 1.4.

Parameters:
  • count – an integer COUNT parameter, or a SQL expression that provides an integer result. When percent=True this will represent the percentage of rows to return, not the absolute value. Pass None to reset it.

  • with_ties – When True, the WITH TIES option is used to return any additional rows that tie for the last place in the result set according to the ORDER BY clause. The ORDER BY may be mandatory in this case. Defaults to False

  • percent – When True, count represents the percentage of the total number of selected rows to return. Defaults to False

method sqlalchemy.sql.expression.Select.filter(*criteria)

A synonym for the Select.where() method.

method sqlalchemy.sql.expression.Select.filter_by(**kwargs)

apply the given filtering criterion as a WHERE clause to this select.

method sqlalchemy.sql.expression.Select.from_statement(statement)

Apply the columns which this Select would select onto another statement.

This operation is plugin-specific and will raise a not supported exception if this Select does not select from plugin-enabled entities.

The statement is typically either a text() or select() construct, and should return the set of columns appropriate to the entities represented by this Select.

See also

Getting ORM Results from Textual and Core Statements - usage examples in the ORM Querying Guide

attribute sqlalchemy.sql.expression.Select.froms

Return the displayed list of FromClause elements.

Deprecated since version 1.4.23: The Select.froms attribute is moved to the Select.get_final_froms() method.

method sqlalchemy.sql.expression.Select.get_children(**kwargs)

Return immediate child Traversible elements of this Traversible.

This is used for visit traversal.

**kw may contain flags that change the collection that is returned, for example to return a subset of items in order to cut down on larger traversals, or to return child items from a different context (such as schema-level collections instead of clause-level).

method sqlalchemy.sql.expression.Select.get_execution_options()

inherited from the Executable.get_execution_options() method of Executable

Get the non-SQL options which will take effect during execution.

New in version 1.3.

method sqlalchemy.sql.expression.Select.get_final_froms()

Compute the final displayed list of FromClause elements.

This method will run through the full computation required to determine what FROM elements will be displayed in the resulting SELECT statement, including shadowing individual tables with JOIN objects, as well as full computation for ORM use cases including eager loading clauses.

For ORM use, this accessor returns the post compilation list of FROM objects; this collection will include elements such as eagerly loaded tables and joins. The objects will not be ORM enabled and not work as a replacement for the Select.select_froms() collection; additionally, the method is not well performing for an ORM enabled statement as it will incur the full ORM construction process.

To retrieve the FROM list that’s implied by the “columns” collection passed to the Select originally, use the Select.columns_clause_froms accessor.

To select from an alternative set of columns while maintaining the FROM list, use the Select.with_only_columns() method and pass the Select.with_only_columns.maintain_column_froms parameter.

New in version 1.4.23: - the Select.get_final_froms() method replaces the previous Select.froms accessor, which is deprecated.

method sqlalchemy.sql.expression.Select.get_label_style()

Retrieve the current label style.

New in version 1.4.

method sqlalchemy.sql.expression.Select.group_by(*clauses)

inherited from the GenerativeSelect.group_by() method of GenerativeSelect

Return a new selectable with the given list of GROUP BY criterion applied.

All existing GROUP BY settings can be suppressed by passing None.

e.g.:

stmt = select(table.c.name, func.max(table.c.stat)).\
group_by(table.c.name)
Parameters:

*clauses – a series of ColumnElement constructs which will be used to generate an GROUP BY clause.

method sqlalchemy.sql.expression.Select.having(having)

Return a new select() construct with the given expression added to its HAVING clause, joined to the existing clause via AND, if any.

attribute sqlalchemy.sql.expression.Select.inner_columns

An iterator of all ColumnElement expressions which would be rendered into the columns clause of the resulting SELECT statement.

This method is legacy as of 1.4 and is superseded by the Select.exported_columns collection.

method sqlalchemy.sql.expression.Select.intersect(*other, **kwargs)

Return a SQL INTERSECT of this select() construct against the given selectables provided as positional arguments.

Parameters:
  • *other

    one or more elements with which to create a UNION.

    Changed in version 1.4.28: multiple elements are now accepted.

  • **kwargs – keyword arguments are forwarded to the constructor for the newly created CompoundSelect object.

method sqlalchemy.sql.expression.Select.intersect_all(*other, **kwargs)

Return a SQL INTERSECT ALL of this select() construct against the given selectables provided as positional arguments.

Parameters:
  • *other

    one or more elements with which to create a UNION.

    Changed in version 1.4.28: multiple elements are now accepted.

  • **kwargs – keyword arguments are forwarded to the constructor for the newly created CompoundSelect object.

method sqlalchemy.sql.expression.Select.join(target, onclause=None, isouter=False, full=False)

Create a SQL JOIN against this Select object’s criterion and apply generatively, returning the newly resulting Select.

E.g.:

stmt = select(user_table).join(address_table, user_table.c.id == address_table.c.user_id)

The above statement generates SQL similar to:

SELECT user.id, user.name FROM user JOIN address ON user.id = address.user_id

Changed in version 1.4: Select.join() now creates a Join object between a FromClause source that is within the FROM clause of the existing SELECT, and a given target FromClause, and then adds this Join to the FROM clause of the newly generated SELECT statement. This is completely reworked from the behavior in 1.3, which would instead create a subquery of the entire Select and then join that subquery to the target.

This is a backwards incompatible change as the previous behavior was mostly useless, producing an unnamed subquery rejected by most databases in any case. The new behavior is modeled after that of the very successful Query.join() method in the ORM, in order to support the functionality of Query being available by using a Select object with an Session.

See the notes for this change at select().join() and outerjoin() add JOIN criteria to the current query, rather than creating a subquery.

Parameters:
  • target – target table to join towards

  • onclause – ON clause of the join. If omitted, an ON clause is generated automatically based on the ForeignKey linkages between the two tables, if one can be unambiguously determined, otherwise an error is raised.

  • isouter – if True, generate LEFT OUTER join. Same as Select.outerjoin().

  • full – if True, generate FULL OUTER join.

method sqlalchemy.sql.expression.Select.join_from(from_, target, onclause=None, isouter=False, full=False)

Create a SQL JOIN against this Select object’s criterion and apply generatively, returning the newly resulting Select.

E.g.:

stmt = select(user_table, address_table).join_from(
    user_table, address_table, user_table.c.id == address_table.c.user_id
)

The above statement generates SQL similar to:

SELECT user.id, user.name, address.id, address.email, address.user_id
FROM user JOIN address ON user.id = address.user_id

New in version 1.4.

Parameters:
  • from_ – the left side of the join, will be rendered in the FROM clause and is roughly equivalent to using the Select.select_from() method.

  • target – target table to join towards

  • onclause – ON clause of the join.

  • isouter – if True, generate LEFT OUTER join. Same as Select.outerjoin().

  • full – if True, generate FULL OUTER join.

method sqlalchemy.sql.expression.Select.label(name)

inherited from the SelectBase.label() method of SelectBase

Return a ‘scalar’ representation of this selectable, embedded as a subquery with a label.

method sqlalchemy.sql.expression.Select.lateral(name=None)

inherited from the SelectBase.lateral() method of SelectBase

Return a LATERAL alias of this Selectable.

The return value is the Lateral construct also provided by the top-level lateral() function.

New in version 1.1.

See also

LATERAL correlation - overview of usage.

method sqlalchemy.sql.expression.Select.limit(limit)

inherited from the GenerativeSelect.limit() method of GenerativeSelect

Return a new selectable with the given LIMIT criterion applied.

This is a numerical value which usually renders as a LIMIT expression in the resulting select. Backends that don’t support LIMIT will attempt to provide similar functionality.

Note

The GenerativeSelect.limit() method will replace any clause applied with GenerativeSelect.fetch().

Changed in version 1.0.0: - Select.limit() can now accept arbitrary SQL expressions as well as integer values.

Parameters:

limit – an integer LIMIT parameter, or a SQL expression that provides an integer result. Pass None to reset it.

method sqlalchemy.sql.expression.Select.offset(offset)

inherited from the GenerativeSelect.offset() method of GenerativeSelect

Return a new selectable with the given OFFSET criterion applied.

This is a numeric value which usually renders as an OFFSET expression in the resulting select. Backends that don’t support OFFSET will attempt to provide similar functionality.

Changed in version 1.0.0: - Select.offset() can now accept arbitrary SQL expressions as well as integer values.

Parameters:

offset – an integer OFFSET parameter, or a SQL expression that provides an integer result. Pass None to reset it.

method sqlalchemy.sql.expression.Select.options(*options)

inherited from the Executable.options() method of Executable

Apply options to this statement.

In the general sense, options are any kind of Python object that can be interpreted by the SQL compiler for the statement. These options can be consumed by specific dialects or specific kinds of compilers.

The most commonly known kind of option are the ORM level options that apply “eager load” and other loading behaviors to an ORM query. However, options can theoretically be used for many other purposes.

For background on specific kinds of options for specific kinds of statements, refer to the documentation for those option objects.

Changed in version 1.4: - added Generative.options() to Core statement objects towards the goal of allowing unified Core / ORM querying capabilities.

See also

Deferred Column Loader Query Options - refers to options specific to the usage of ORM queries

Relationship Loading with Loader Options - refers to options specific to the usage of ORM queries

method sqlalchemy.sql.expression.Select.order_by(*clauses)

inherited from the GenerativeSelect.order_by() method of GenerativeSelect

Return a new selectable with the given list of ORDER BY criteria applied.

e.g.:

stmt = select(table).order_by(table.c.id, table.c.name)

Calling this method multiple times is equivalent to calling it once with all the clauses concatenated. All existing ORDER BY criteria may be cancelled by passing None by itself. New ORDER BY criteria may then be added by invoking Query.order_by() again, e.g.:

# will erase all ORDER BY and ORDER BY new_col alone
stmt = stmt.order_by(None).order_by(new_col)
Parameters:

*clauses – a series of ColumnElement constructs which will be used to generate an ORDER BY clause.

method sqlalchemy.sql.expression.Select.outerjoin(target, onclause=None, full=False)

Create a left outer join.

Parameters are the same as that of Select.join().

Changed in version 1.4: Select.outerjoin() now creates a Join object between a FromClause source that is within the FROM clause of the existing SELECT, and a given target FromClause, and then adds this Join to the FROM clause of the newly generated SELECT statement. This is completely reworked from the behavior in 1.3, which would instead create a subquery of the entire Select and then join that subquery to the target.

This is a backwards incompatible change as the previous behavior was mostly useless, producing an unnamed subquery rejected by most databases in any case. The new behavior is modeled after that of the very successful Query.join() method in the ORM, in order to support the functionality of Query being available by using a Select object with an Session.

See the notes for this change at select().join() and outerjoin() add JOIN criteria to the current query, rather than creating a subquery.

method sqlalchemy.sql.expression.Select.outerjoin_from(from_, target, onclause=None, full=False)

Create a SQL LEFT OUTER JOIN against this Select object’s criterion and apply generatively, returning the newly resulting Select.

Usage is the same as that of Select.join_from().

method sqlalchemy.sql.expression.Select.prefix_with(*expr, **kw)

inherited from the HasPrefixes.prefix_with() method of HasPrefixes

Add one or more expressions following the statement keyword, i.e. SELECT, INSERT, UPDATE, or DELETE. Generative.

This is used to support backend-specific prefix keywords such as those provided by MySQL.

E.g.:

stmt = table.insert().prefix_with("LOW_PRIORITY", dialect="mysql")

# MySQL 5.7 optimizer hints
stmt = select(table).prefix_with(
    "/*+ BKA(t1) */", dialect="mysql")

Multiple prefixes can be specified by multiple calls to HasPrefixes.prefix_with().

Parameters:
  • *expr – textual or ClauseElement construct which will be rendered following the INSERT, UPDATE, or DELETE keyword.

  • **kw – A single keyword ‘dialect’ is accepted. This is an optional string dialect name which will limit rendering of this prefix to only that dialect.

method sqlalchemy.sql.expression.Select.reduce_columns(only_synonyms=True)

Return a new select() construct with redundantly named, equivalently-valued columns removed from the columns clause.

“Redundant” here means two columns where one refers to the other either based on foreign key, or via a simple equality comparison in the WHERE clause of the statement. The primary purpose of this method is to automatically construct a select statement with all uniquely-named columns, without the need to use table-qualified labels as Select.set_label_style() does.

When columns are omitted based on foreign key, the referred-to column is the one that’s kept. When columns are omitted based on WHERE equivalence, the first column in the columns clause is the one that’s kept.

Parameters:

only_synonyms – when True, limit the removal of columns to those which have the same name as the equivalent. Otherwise, all columns that are equivalent to another are removed.

method sqlalchemy.sql.expression.Select.replace_selectable(old, alias)

inherited from the Selectable.replace_selectable() method of Selectable

Replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

Deprecated since version 1.4: The Selectable.replace_selectable() method is deprecated, and will be removed in a future release. Similar functionality is available via the sqlalchemy.sql.visitors module.

method sqlalchemy.sql.expression.Select.scalar(*multiparams, **params)

inherited from the Executable.scalar() method of Executable

Compile and execute this Executable, returning the result’s scalar representation.

Deprecated since version 1.4: The Executable.scalar() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Scalar execution in SQLAlchemy 2.0 is performed by the Connection.scalar() method of Connection, or in the ORM by the Session.scalar() method of Session. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

method sqlalchemy.sql.expression.Select.scalar_subquery()

inherited from the SelectBase.scalar_subquery() method of SelectBase

Return a ‘scalar’ representation of this selectable, which can be used as a column expression.

The returned object is an instance of ScalarSelect.

Typically, a select statement which has only one column in its columns clause is eligible to be used as a scalar expression. The scalar subquery can then be used in the WHERE clause or columns clause of an enclosing SELECT.

Note that the scalar subquery differentiates from the FROM-level subquery that can be produced using the SelectBase.subquery() method.

See also

Scalar and Correlated Subqueries - in the 2.0 tutorial

method sqlalchemy.sql.expression.Select.select(*arg, **kw)

inherited from the SelectBase.select() method of SelectBase

Deprecated since version 1.4: The SelectBase.select() method is deprecated and will be removed in a future release; this method implicitly creates a subquery that should be explicit. Please call SelectBase.subquery() first in order to create a subquery, which then can be selected.

method sqlalchemy.sql.expression.Select.select_from(*froms)

Return a new select() construct with the given FROM expression(s) merged into its list of FROM objects.

E.g.:

table1 = table('t1', column('a'))
table2 = table('t2', column('b'))
s = select(table1.c.a).\
    select_from(
        table1.join(table2, table1.c.a==table2.c.b)
    )

The “from” list is a unique set on the identity of each element, so adding an already present Table or other selectable will have no effect. Passing a Join that refers to an already present Table or other selectable will have the effect of concealing the presence of that selectable as an individual element in the rendered FROM list, instead rendering it into a JOIN clause.

While the typical purpose of Select.select_from() is to replace the default, derived FROM clause with a join, it can also be called with individual table elements, multiple times if desired, in the case that the FROM clause cannot be fully derived from the columns clause:

select(func.count('*')).select_from(table1)
attribute sqlalchemy.sql.expression.Select.selected_columns

A ColumnCollection representing the columns that this SELECT statement or similar construct returns in its result set, not including TextClause constructs.

This collection differs from the FromClause.columns collection of a FromClause in that the columns within this collection cannot be directly nested inside another SELECT statement; a subquery must be applied first which provides for the necessary parenthesization required by SQL.

For a select() construct, the collection here is exactly what would be rendered inside the “SELECT” statement, and the ColumnElement objects are directly present as they were given, e.g.:

col1 = column('q', Integer)
col2 = column('p', Integer)
stmt = select(col1, col2)

Above, stmt.selected_columns would be a collection that contains the col1 and col2 objects directly. For a statement that is against a Table or other FromClause, the collection will use the ColumnElement objects that are in the FromClause.c collection of the from element.

Note

The Select.selected_columns collection does not include expressions established in the columns clause using the text() construct; these are silently omitted from the collection. To use plain textual column expressions inside of a Select construct, use the literal_column() construct.

New in version 1.4.

method sqlalchemy.sql.expression.Select.self_group(against=None)

Return a ‘grouping’ construct as per the ClauseElement specification.

This produces an element that can be embedded in an expression. Note that this method is called automatically as needed when constructing expressions and should not require explicit use.

method sqlalchemy.sql.expression.Select.set_label_style(style)

Return a new selectable with the specified label style.

There are three “label styles” available, LABEL_STYLE_DISAMBIGUATE_ONLY, LABEL_STYLE_TABLENAME_PLUS_COL, and LABEL_STYLE_NONE. The default style is LABEL_STYLE_DISAMBIGUATE_ONLY.

In modern SQLAlchemy, there is not generally a need to change the labeling style, as per-expression labels are more effectively used by making use of the ColumnElement.label() method. In past versions, LABEL_STYLE_TABLENAME_PLUS_COL was used to disambiguate same-named columns from different tables, aliases, or subqueries; the newer LABEL_STYLE_DISAMBIGUATE_ONLY now applies labels only to names that conflict with an existing name so that the impact of this labeling is minimal.

The rationale for disambiguation is mostly so that all column expressions are available from a given FromClause.c collection when a subquery is created.

New in version 1.4: - the GenerativeSelect.set_label_style() method replaces the previous combination of .apply_labels(), .with_labels() and use_labels=True methods and/or parameters.

method sqlalchemy.sql.expression.Select.slice(start, stop)

inherited from the GenerativeSelect.slice() method of GenerativeSelect

Apply LIMIT / OFFSET to this statement based on a slice.

The start and stop indices behave like the argument to Python’s built-in range() function. This method provides an alternative to using LIMIT/OFFSET to get a slice of the query.

For example,

stmt = select(User).order_by(User.id).slice(1, 3)

renders as

SELECT users.id AS users_id,
       users.name AS users_name
FROM users ORDER BY users.id
LIMIT ? OFFSET ?
(2, 1)

Note

The GenerativeSelect.slice() method will replace any clause applied with GenerativeSelect.fetch().

New in version 1.4: Added the GenerativeSelect.slice() method generalized from the ORM.

method sqlalchemy.sql.expression.Select.subquery(name=None)

inherited from the SelectBase.subquery() method of SelectBase

Return a subquery of this SelectBase.

A subquery is from a SQL perspective a parenthesized, named construct that can be placed in the FROM clause of another SELECT statement.

Given a SELECT statement such as:

stmt = select(table.c.id, table.c.name)

The above statement might look like:

SELECT table.id, table.name FROM table

The subquery form by itself renders the same way, however when embedded into the FROM clause of another SELECT statement, it becomes a named sub-element:

subq = stmt.subquery()
new_stmt = select(subq)

The above renders as:

SELECT anon_1.id, anon_1.name
FROM (SELECT table.id, table.name FROM table) AS anon_1

Historically, SelectBase.subquery() is equivalent to calling the FromClause.alias() method on a FROM object; however, as a SelectBase object is not directly FROM object, the SelectBase.subquery() method provides clearer semantics.

New in version 1.4.

method sqlalchemy.sql.expression.Select.suffix_with(*expr, **kw)

inherited from the HasSuffixes.suffix_with() method of HasSuffixes

Add one or more expressions following the statement as a whole.

This is used to support backend-specific suffix keywords on certain constructs.

E.g.:

stmt = select(col1, col2).cte().suffix_with(
    "cycle empno set y_cycle to 1 default 0", dialect="oracle")

Multiple suffixes can be specified by multiple calls to HasSuffixes.suffix_with().

Parameters:
  • *expr – textual or ClauseElement construct which will be rendered following the target clause.

  • **kw – A single keyword ‘dialect’ is accepted. This is an optional string dialect name which will limit rendering of this suffix to only that dialect.

method sqlalchemy.sql.expression.Select.union(*other, **kwargs)

Return a SQL UNION of this select() construct against the given selectables provided as positional arguments.

Parameters:
  • *other

    one or more elements with which to create a UNION.

    Changed in version 1.4.28: multiple elements are now accepted.

  • **kwargs – keyword arguments are forwarded to the constructor for the newly created CompoundSelect object.

method sqlalchemy.sql.expression.Select.union_all(*other, **kwargs)

Return a SQL UNION ALL of this select() construct against the given selectables provided as positional arguments.

Parameters:
  • *other

    one or more elements with which to create a UNION.

    Changed in version 1.4.28: multiple elements are now accepted.

  • **kwargs – keyword arguments are forwarded to the constructor for the newly created CompoundSelect object.

method sqlalchemy.sql.expression.Select.where(*whereclause)

Return a new select() construct with the given expression added to its WHERE clause, joined to the existing clause via AND, if any.

attribute sqlalchemy.sql.expression.Select.whereclause

Return the completed WHERE clause for this Select statement.

This assembles the current collection of WHERE criteria into a single BooleanClauseList construct.

New in version 1.4.

method sqlalchemy.sql.expression.Select.with_for_update(nowait=False, read=False, of=None, skip_locked=False, key_share=False)

Specify a FOR UPDATE clause for this GenerativeSelect.

E.g.:

stmt = select(table).with_for_update(nowait=True)

On a database like PostgreSQL or Oracle, the above would render a statement like:

SELECT table.a, table.b FROM table FOR UPDATE NOWAIT

on other backends, the nowait option is ignored and instead would produce:

SELECT table.a, table.b FROM table FOR UPDATE

When called with no arguments, the statement will render with the suffix FOR UPDATE. Additional arguments can then be provided which allow for common database-specific variants.

Parameters:
  • nowait – boolean; will render FOR UPDATE NOWAIT on Oracle and PostgreSQL dialects.

  • read – boolean; will render LOCK IN SHARE MODE on MySQL, FOR SHARE on PostgreSQL. On PostgreSQL, when combined with nowait, will render FOR SHARE NOWAIT.

  • of – SQL expression or list of SQL expression elements (typically Column objects or a compatible expression) which will render into a FOR UPDATE OF clause; supported by PostgreSQL and Oracle. May render as a table or as a column depending on backend.

  • skip_locked – boolean, will render FOR UPDATE SKIP LOCKED on Oracle and PostgreSQL dialects or FOR SHARE SKIP LOCKED if read=True is also specified.

  • key_share – boolean, will render FOR NO KEY UPDATE, or if combined with read=True will render FOR KEY SHARE, on the PostgreSQL dialect.

method sqlalchemy.sql.expression.Select.with_hint(selectable, text, dialect_name='*')

inherited from the HasHints.with_hint() method of HasHints

Add an indexing or other executional context hint for the given selectable to this Select or other selectable object.

The text of the hint is rendered in the appropriate location for the database backend in use, relative to the given Table or Alias passed as the selectable argument. The dialect implementation typically uses Python string substitution syntax with the token %(name)s to render the name of the table or alias. E.g. when using Oracle, the following:

select(mytable).\
    with_hint(mytable, "index(%(name)s ix_mytable)")

Would render SQL as:

select /*+ index(mytable ix_mytable) */ ... from mytable

The dialect_name option will limit the rendering of a particular hint to a particular backend. Such as, to add hints for both Oracle and Sybase simultaneously:

select(mytable).\
    with_hint(mytable, "index(%(name)s ix_mytable)", 'oracle').\
    with_hint(mytable, "WITH INDEX ix_mytable", 'sybase')
method sqlalchemy.sql.expression.Select.with_only_columns(*columns, **kw)

Return a new select() construct with its columns clause replaced with the given columns.

By default, this method is exactly equivalent to as if the original select() had been called with the given columns clause. E.g. a statement:

s = select(table1.c.a, table1.c.b)
s = s.with_only_columns(table1.c.b)

should be exactly equivalent to:

s = select(table1.c.b)

In this mode of operation, Select.with_only_columns() will also dynamically alter the FROM clause of the statement if it is not explicitly stated. To maintain the existing set of FROMs including those implied by the current columns clause, add the Select.with_only_columns.maintain_column_froms parameter:

s = select(table1.c.a, table2.c.b)
s = s.with_only_columns(table1.c.a, maintain_column_froms=True)

The above parameter performs a transfer of the effective FROMs in the columns collection to the Select.select_from() method, as though the following were invoked:

s = select(table1.c.a, table2.c.b)
s = s.select_from(table1, table2).with_only_columns(table1.c.a)

The Select.with_only_columns.maintain_column_froms parameter makes use of the Select.columns_clause_froms collection and performs an operation equivalent to the following:

s = select(table1.c.a, table2.c.b)
s = s.select_from(*s.columns_clause_froms).with_only_columns(table1.c.a)
Parameters:
  • *columns

    column expressions to be used.

    Changed in version 1.4: the Select.with_only_columns() method accepts the list of column expressions positionally; passing the expressions as a list is deprecated.

  • maintain_column_froms

    boolean parameter that will ensure the FROM list implied from the current columns clause will be transferred to the Select.select_from() method first.

    New in version 1.4.23.

method sqlalchemy.sql.expression.Select.with_statement_hint(text, dialect_name='*')

inherited from the HasHints.with_statement_hint() method of HasHints

Add a statement hint to this Select or other selectable object.

This method is similar to Select.with_hint() except that it does not require an individual table, and instead applies to the statement as a whole.

Hints here are specific to the backend database and may include directives such as isolation levels, file directives, fetch directives, etc.

New in version 1.0.0.

See also

Select.with_hint()

Select.prefix_with() - generic SELECT prefixing which also can suit some database-specific HINT syntaxes such as MySQL optimizer hints

class sqlalchemy.sql.expression.Selectable

Mark a class as being selectable.

method sqlalchemy.sql.expression.Selectable.corresponding_column(column, require_embedded=False)

Given a ColumnElement, return the exported ColumnElement object from the Selectable.exported_columns collection of this Selectable which corresponds to that original ColumnElement via a common ancestor column.

Parameters:
  • column – the target ColumnElement to be matched.

  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this Selectable. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this Selectable.

See also

Selectable.exported_columns - the ColumnCollection that is used for the operation.

ColumnCollection.corresponding_column() - implementation method.

attribute sqlalchemy.sql.expression.Selectable.exported_columns

inherited from the ReturnsRows.exported_columns attribute of ReturnsRows

A ColumnCollection that represents the “exported” columns of this ReturnsRows.

The “exported” columns represent the collection of ColumnElement expressions that are rendered by this SQL construct. There are primary varieties which are the “FROM clause columns” of a FROM clause, such as a table, join, or subquery, the “SELECTed columns”, which are the columns in the “columns clause” of a SELECT statement, and the RETURNING columns in a DML statement..

New in version 1.4.

method sqlalchemy.sql.expression.Selectable.lateral(name=None)

Return a LATERAL alias of this Selectable.

The return value is the Lateral construct also provided by the top-level lateral() function.

New in version 1.1.

See also

LATERAL correlation - overview of usage.

method sqlalchemy.sql.expression.Selectable.replace_selectable(old, alias)

Replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

Deprecated since version 1.4: The Selectable.replace_selectable() method is deprecated, and will be removed in a future release. Similar functionality is available via the sqlalchemy.sql.visitors module.

class sqlalchemy.sql.expression.SelectBase

Base class for SELECT statements.

This includes Select, CompoundSelect and TextualSelect.

Class signature

class sqlalchemy.sql.expression.SelectBase (sqlalchemy.sql.roles.SelectStatementRole, sqlalchemy.sql.roles.DMLSelectRole, sqlalchemy.sql.roles.CompoundElementRole, sqlalchemy.sql.roles.InElementRole, sqlalchemy.sql.expression.HasCTE, sqlalchemy.sql.expression.Executable, sqlalchemy.sql.annotation.SupportsCloneAnnotations, sqlalchemy.sql.expression.Selectable)

method sqlalchemy.sql.expression.SelectBase.add_cte(cte)

inherited from the HasCTE.add_cte() method of HasCTE

Add a CTE to this statement object that will be independently rendered even if not referenced in the statement otherwise.

This feature is useful for the use case of embedding a DML statement such as an INSERT or UPDATE as a CTE inline with a primary statement that may draw from its results indirectly; while PostgreSQL is known to support this usage, it may not be supported by other backends.

E.g.:

from sqlalchemy import table, column, select
t = table('t', column('c1'), column('c2'))

ins = t.insert().values({"c1": "x", "c2": "y"}).cte()

stmt = select(t).add_cte(ins)

Would render:

WITH anon_1 AS
(INSERT INTO t (c1, c2) VALUES (:param_1, :param_2))
SELECT t.c1, t.c2
FROM t

Above, the “anon_1” CTE is not referred towards in the SELECT statement, however still accomplishes the task of running an INSERT statement.

Similarly in a DML-related context, using the PostgreSQL Insert construct to generate an “upsert”:

from sqlalchemy import table, column
from sqlalchemy.dialects.postgresql import insert

t = table("t", column("c1"), column("c2"))

delete_statement_cte = (
    t.delete().where(t.c.c1 < 1).cte("deletions")
)

insert_stmt = insert(t).values({"c1": 1, "c2": 2})
update_statement = insert_stmt.on_conflict_do_update(
    index_elements=[t.c.c1],
    set_={
        "c1": insert_stmt.excluded.c1,
        "c2": insert_stmt.excluded.c2,
    },
).add_cte(delete_statement_cte)

print(update_statement)

The above statement renders as:

WITH deletions AS
(DELETE FROM t WHERE t.c1 < %(c1_1)s)
INSERT INTO t (c1, c2) VALUES (%(c1)s, %(c2)s)
ON CONFLICT (c1) DO UPDATE SET c1 = excluded.c1, c2 = excluded.c2

New in version 1.4.21.

method sqlalchemy.sql.expression.SelectBase.alias(name=None, flat=False)

Return a named subquery against this SelectBase.

For a SelectBase (as opposed to a FromClause), this returns a Subquery object which behaves mostly the same as the Alias object that is used with a FromClause.

Changed in version 1.4: The SelectBase.alias() method is now a synonym for the SelectBase.subquery() method.

method sqlalchemy.sql.expression.SelectBase.as_scalar()

Deprecated since version 1.4: The SelectBase.as_scalar() method is deprecated and will be removed in a future release. Please refer to SelectBase.scalar_subquery().

attribute sqlalchemy.sql.expression.SelectBase.bind

inherited from the Executable.bind attribute of Executable

Returns the Engine or Connection to which this Executable is bound, or None if none found.

Deprecated since version 1.4: The Executable.bind attribute is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Bound metadata is being removed as of SQLAlchemy 2.0. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

This is a traversal which checks locally, then checks among the “from” clauses of associated objects until a bound engine or connection is found.

attribute sqlalchemy.sql.expression.SelectBase.c

Deprecated since version 1.4: The SelectBase.c and SelectBase.columns attributes are deprecated and will be removed in a future release; these attributes implicitly create a subquery that should be explicit. Please call SelectBase.subquery() first in order to create a subquery, which then contains this attribute. To access the columns that this SELECT object SELECTs from, use the SelectBase.selected_columns attribute.

method sqlalchemy.sql.expression.SelectBase.corresponding_column(column, require_embedded=False)

inherited from the Selectable.corresponding_column() method of Selectable

Given a ColumnElement, return the exported ColumnElement object from the Selectable.exported_columns collection of this Selectable which corresponds to that original ColumnElement via a common ancestor column.

Parameters:
  • column – the target ColumnElement to be matched.

  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this Selectable. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this Selectable.

See also

Selectable.exported_columns - the ColumnCollection that is used for the operation.

ColumnCollection.corresponding_column() - implementation method.

method sqlalchemy.sql.expression.SelectBase.cte(name=None, recursive=False, nesting=False)

inherited from the HasCTE.cte() method of HasCTE

Return a new CTE, or Common Table Expression instance.

Common table expressions are a SQL standard whereby SELECT statements can draw upon secondary statements specified along with the primary statement, using a clause called “WITH”. Special semantics regarding UNION can also be employed to allow “recursive” queries, where a SELECT statement can draw upon the set of rows that have previously been selected.

CTEs can also be applied to DML constructs UPDATE, INSERT and DELETE on some databases, both as a source of CTE rows when combined with RETURNING, as well as a consumer of CTE rows.

Changed in version 1.1: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.

SQLAlchemy detects CTE objects, which are treated similarly to Alias objects, as special elements to be delivered to the FROM clause of the statement as well as to a WITH clause at the top of the statement.

For special prefixes such as PostgreSQL “MATERIALIZED” and “NOT MATERIALIZED”, the CTE.prefix_with() method may be used to establish these.

Changed in version 1.3.13: Added support for prefixes. In particular - MATERIALIZED and NOT MATERIALIZED.

Parameters:
  • name – name given to the common table expression. Like FromClause.alias(), the name can be left as None in which case an anonymous symbol will be used at query compile time.

  • recursive – if True, will render WITH RECURSIVE. A recursive common table expression is intended to be used in conjunction with UNION ALL in order to derive rows from those already selected.

  • nesting

    if True, will render the CTE locally to the actual statement.

    New in version 1.4.24.

The following examples include two from PostgreSQL’s documentation at https://www.postgresql.org/docs/current/static/queries-with.html, as well as additional examples.

Example 1, non recursive:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

orders = Table('orders', metadata,
    Column('region', String),
    Column('amount', Integer),
    Column('product', String),
    Column('quantity', Integer)
)

regional_sales = select(
                    orders.c.region,
                    func.sum(orders.c.amount).label('total_sales')
                ).group_by(orders.c.region).cte("regional_sales")


top_regions = select(regional_sales.c.region).\
        where(
            regional_sales.c.total_sales >
            select(
                func.sum(regional_sales.c.total_sales) / 10
            )
        ).cte("top_regions")

statement = select(
            orders.c.region,
            orders.c.product,
            func.sum(orders.c.quantity).label("product_units"),
            func.sum(orders.c.amount).label("product_sales")
    ).where(orders.c.region.in_(
        select(top_regions.c.region)
    )).group_by(orders.c.region, orders.c.product)

result = conn.execute(statement).fetchall()

Example 2, WITH RECURSIVE:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

parts = Table('parts', metadata,
    Column('part', String),
    Column('sub_part', String),
    Column('quantity', Integer),
)

included_parts = select(\
    parts.c.sub_part, parts.c.part, parts.c.quantity\
    ).\
    where(parts.c.part=='our part').\
    cte(recursive=True)


incl_alias = included_parts.alias()
parts_alias = parts.alias()
included_parts = included_parts.union_all(
    select(
        parts_alias.c.sub_part,
        parts_alias.c.part,
        parts_alias.c.quantity
    ).\
    where(parts_alias.c.part==incl_alias.c.sub_part)
)

statement = select(
            included_parts.c.sub_part,
            func.sum(included_parts.c.quantity).
              label('total_quantity')
        ).\
        group_by(included_parts.c.sub_part)

result = conn.execute(statement).fetchall()

Example 3, an upsert using UPDATE and INSERT with CTEs:

from datetime import date
from sqlalchemy import (MetaData, Table, Column, Integer,
                        Date, select, literal, and_, exists)

metadata = MetaData()

visitors = Table('visitors', metadata,
    Column('product_id', Integer, primary_key=True),
    Column('date', Date, primary_key=True),
    Column('count', Integer),
)

# add 5 visitors for the product_id == 1
product_id = 1
day = date.today()
count = 5

update_cte = (
    visitors.update()
    .where(and_(visitors.c.product_id == product_id,
                visitors.c.date == day))
    .values(count=visitors.c.count + count)
    .returning(literal(1))
    .cte('update_cte')
)

upsert = visitors.insert().from_select(
    [visitors.c.product_id, visitors.c.date, visitors.c.count],
    select(literal(product_id), literal(day), literal(count))
        .where(~exists(update_cte.select()))
)

connection.execute(upsert)

Example 4, Nesting CTE (SQLAlchemy 1.4.24 and above):

value_a = select(
    literal("root").label("n")
).cte("value_a")

# A nested CTE with the same name as the root one
value_a_nested = select(
    literal("nesting").label("n")
).cte("value_a", nesting=True)

# Nesting CTEs takes ascendency locally
# over the CTEs at a higher level
value_b = select(value_a_nested.c.n).cte("value_b")

value_ab = select(value_a.c.n.label("a"), value_b.c.n.label("b"))

The above query will render the second CTE nested inside the first, shown with inline parameters below as:

WITH
    value_a AS
        (SELECT 'root' AS n),
    value_b AS
        (WITH value_a AS
            (SELECT 'nesting' AS n)
        SELECT value_a.n AS n FROM value_a)
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"