Query API

This section presents the API reference for the ORM Query object. For a walkthrough of how to use this object, see Object Relational Tutorial (1.x API).

The Query Object

Query is produced in terms of a given Session, using the Session.query() method:

q = session.query(SomeMappedClass)

Following is the full interface for the Query object.

Object Name Description

Query

ORM-level SQL construction object.

class sqlalchemy.orm.Query(entities, session=None)

ORM-level SQL construction object.

Query is the source of all SELECT statements generated by the ORM, both those formulated by end-user query operations as well as by high level internal operations such as related collection loading. It features a generative interface whereby successive calls return a new Query object, a copy of the former with additional criteria and options associated with it.

Query objects are normally initially generated using the Session.query() method of Session, and in less common cases by instantiating the Query directly and associating with a Session using the Query.with_session() method.

For a full walk through of Query usage, see the Object Relational Tutorial (1.x API).

Class signature

class sqlalchemy.orm.Query (sqlalchemy.sql.expression._SelectFromElements, sqlalchemy.sql.annotation.SupportsCloneAnnotations, sqlalchemy.sql.expression.HasPrefixes, sqlalchemy.sql.expression.HasSuffixes, sqlalchemy.sql.expression.HasHints, sqlalchemy.sql.expression.Executable)

method sqlalchemy.orm.Query.__init__(entities, session=None)

Construct a Query directly.

E.g.:

q = Query([User, Address], session=some_session)

The above is equivalent to:

q = some_session.query(User, Address)
Parameters:
  • entities – a sequence of entities and/or SQL expressions.

  • session – a Session with which the Query will be associated. Optional; a Query can be associated with a Session generatively via the Query.with_session() method as well.

method sqlalchemy.orm.Query.add_column(column)

Add a column expression to the list of result columns to be returned.

Deprecated since version 1.4: Query.add_column() is deprecated and will be removed in a future release. Please use Query.add_columns()

method sqlalchemy.orm.Query.add_columns(*column)

Add one or more column expressions to the list of result columns to be returned.

method sqlalchemy.orm.Query.add_entity(entity, alias=None)

add a mapped entity to the list of result columns to be returned.

method sqlalchemy.orm.Query.all()

Return the results represented by this Query as a list.

This results in an execution of the underlying SQL statement.

Warning

The Query object, when asked to return either a sequence or iterator that consists of full ORM-mapped entities, will deduplicate entries based on primary key. See the FAQ for more details.

method sqlalchemy.orm.Query.apply_labels()

Deprecated since version 1.4: The Query.with_labels() and Query.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.orm.Query.as_scalar()

Return the full SELECT statement represented by this Query, converted to a scalar subquery.

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

method sqlalchemy.orm.Query.autoflush(setting)

Return a Query with a specific ‘autoflush’ setting.

As of SQLAlchemy 1.4, the Query.autoflush() method is equivalent to using the autoflush execution option at the ORM level. See the section Autoflush for further background on this option.

attribute sqlalchemy.orm.Query.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.orm.Query.column_descriptions

Return metadata about the columns which would be returned by this Query.

Format is a list of dictionaries:

user_alias = aliased(User, name='user2')
q = sess.query(User, User.id, user_alias)

# this expression:
q.column_descriptions

# would return:
[
    {
        'name':'User',
        'type':User,
        'aliased':False,
        'expr':User,
        'entity': User
    },
    {
        'name':'id',
        'type':Integer(),
        'aliased':False,
        'expr':User.id,
        'entity': User
    },
    {
        'name':'user2',
        'type':User,
        'aliased':True,
        'expr':user_alias,
        'entity': user_alias
    }
]

See also

This API is available using 2.0 style queries as well, documented at:

method sqlalchemy.orm.Query.correlate(*fromclauses)

Return a Query construct which will correlate the given FROM clauses to that of an enclosing Query or select().

The method here accepts mapped classes, aliased() constructs, and mapper() constructs as arguments, which are resolved into expression constructs, in addition to appropriate expression constructs.

The correlation arguments are ultimately passed to Select.correlate() after coercion to expression constructs.

The correlation arguments take effect in such cases as when Query.from_self() is used, or when a subquery as returned by Query.subquery() is embedded in another select() construct.

method sqlalchemy.orm.Query.count()

Return a count of rows this the SQL formed by this Query would return.

This generates the SQL for this Query as follows:

SELECT count(1) AS count_1 FROM (
    SELECT <rest of query follows...>
) AS anon_1

The above SQL returns a single row, which is the aggregate value of the count function; the Query.count() method then returns that single integer value.

Warning

It is important to note that the value returned by count() is not the same as the number of ORM objects that this Query would return from a method such as the .all() method. The Query object, when asked to return full entities, will deduplicate entries based on primary key, meaning if the same primary key value would appear in the results more than once, only one object of that primary key would be present. This does not apply to a query that is against individual columns.

For fine grained control over specific columns to count, to skip the usage of a subquery or otherwise control of the FROM clause, or to use other aggregate functions, use expression.func expressions in conjunction with Session.query(), i.e.:

from sqlalchemy import func

# count User records, without
# using a subquery.
session.query(func.count(User.id))

# return count of user "id" grouped
# by "name"
session.query(func.count(User.id)).\
        group_by(User.name)

from sqlalchemy import distinct

# count distinct "name" values
session.query(func.count(distinct(User.name)))
method sqlalchemy.orm.Query.cte(name=None, recursive=False, nesting=False)

Return the full SELECT statement represented by this Query represented as a common table expression (CTE).

Parameters and usage are the same as those of the SelectBase.cte() method; see that method for further details.

Here is the PostgreSQL WITH RECURSIVE example. Note that, in this example, the included_parts cte and the incl_alias alias of it are Core selectables, which means the columns are accessed via the .c. attribute. The parts_alias object is an aliased() instance of the Part entity, so column-mapped attributes are available directly:

from sqlalchemy.orm import aliased

class Part(Base):
    __tablename__ = 'part'
    part = Column(String, primary_key=True)
    sub_part = Column(String, primary_key=True)
    quantity = Column(Integer)

included_parts = session.query(
                Part.sub_part,
                Part.part,
                Part.quantity).\
                    filter(Part.part=="our part").\
                    cte(name="included_parts", recursive=True)

incl_alias = aliased(included_parts, name="pr")
parts_alias = aliased(Part, name="p")
included_parts = included_parts.union_all(
    session.query(
        parts_alias.sub_part,
        parts_alias.part,
        parts_alias.quantity).\
            filter(parts_alias.part==incl_alias.c.sub_part)
    )

q = session.query(
        included_parts.c.sub_part,
        func.sum(included_parts.c.quantity).
            label('total_quantity')
    ).\
    group_by(included_parts.c.sub_part)

See also

HasCTE.cte()

method sqlalchemy.orm.Query.delete(synchronize_session='evaluate')

Perform a DELETE with an arbitrary WHERE clause.

Deletes rows matched by this query from the database.

E.g.:

sess.query(User).filter(User.age == 25).\
    delete(synchronize_session=False)

sess.query(User).filter(User.age == 25).\
    delete(synchronize_session='evaluate')

Warning

See the section UPDATE and DELETE with arbitrary WHERE clause for important caveats and warnings, including limitations when using bulk UPDATE and DELETE with mapper inheritance configurations.

Parameters:

synchronize_session – chooses the strategy to update the attributes on objects in the session. See the section UPDATE and DELETE with arbitrary WHERE clause for a discussion of these strategies.

Returns:

the count of rows matched as returned by the database’s “row count” feature.

method sqlalchemy.orm.Query.distinct(*expr)

Apply a DISTINCT to the query and return the newly resulting Query.

Note

The ORM-level distinct() call includes logic that will automatically add columns from the ORDER BY of the query to the columns clause of the SELECT statement, to satisfy the common need of the database backend that ORDER BY columns be part of the SELECT list when DISTINCT is used. These columns are not added to the list of columns actually fetched by the Query, however, so would not affect results. The columns are passed through when using the Query.statement accessor, however.

Deprecated since version 2.0: This logic is deprecated and will be removed in SQLAlchemy 2.0. See Using DISTINCT with additional columns, but only select the entity for a description of this use case in 2.0.

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.orm.Query.enable_assertions(value)

Control whether assertions are generated.

When set to False, the returned Query will not assert its state before certain operations, including that LIMIT/OFFSET has not been applied when filter() is called, no criterion exists when get() is called, and no “from_statement()” exists when filter()/order_by()/group_by() etc. is called. This more permissive mode is used by custom Query subclasses to specify criterion or other modifiers outside of the usual usage patterns.

Care should be taken to ensure that the usage pattern is even possible. A statement applied by from_statement() will override any criterion set by filter() or order_by(), for example.

method sqlalchemy.orm.Query.enable_eagerloads(value)

Control whether or not eager joins and subqueries are rendered.

When set to False, the returned Query will not render eager joins regardless of joinedload(), subqueryload() options or mapper-level lazy='joined'/lazy='subquery' configurations.

This is used primarily when nesting the Query’s statement into a subquery or other selectable, or when using Query.yield_per().

method sqlalchemy.orm.Query.except_(*q)

Produce an EXCEPT of this Query against one or more queries.

Works the same way as Query.union(). See that method for usage examples.

method sqlalchemy.orm.Query.except_all(*q)

Produce an EXCEPT ALL of this Query against one or more queries.

Works the same way as Query.union(). See that method for usage examples.

method sqlalchemy.orm.Query.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.orm.Query.execution_options(**kwargs)

Set non-SQL options which take effect during execution.

Options allowed here include all of those accepted by Connection.execution_options(), as well as a series of ORM specific options:

populate_existing=True - equivalent to using Query.populate_existing()

autoflush=True|False - equivalent to using Query.autoflush()

yield_per=<value> - equivalent to using Query.yield_per()

Note that the stream_results execution option is enabled automatically if the Query.yield_per() method or execution option is used.

New in version 1.4: - added ORM options to Query.execution_options()

The execution options may also be specified on a per execution basis when using 2.0 style queries via the Session.execution_options parameter.

Warning

The Connection.execution_options.stream_results parameter should not be used at the level of individual ORM statement executions, as the Session will not track objects from different schema translate maps within a single session. For multiple schema translate maps within the scope of a single Session, see Horizontal Sharding.

method sqlalchemy.orm.Query.exists()

A convenience method that turns a query into an EXISTS subquery of the form EXISTS (SELECT 1 FROM … WHERE …).

e.g.:

q = session.query(User).filter(User.name == 'fred')
session.query(q.exists())

Producing SQL similar to:

SELECT EXISTS (
    SELECT 1 FROM users WHERE users.name = :name_1
) AS anon_1

The EXISTS construct is usually used in the WHERE clause:

session.query(User.id).filter(q.exists()).scalar()

Note that some databases such as SQL Server don’t allow an EXISTS expression to be present in the columns clause of a SELECT. To select a simple boolean value based on the exists as a WHERE, use literal():

from sqlalchemy import literal

session.query(literal(True)).filter(q.exists()).scalar()
method sqlalchemy.orm.Query.filter(*criterion)

Apply the given filtering criterion to a copy of this Query, using SQL expressions.

e.g.:

session.query(MyClass).filter(MyClass.name == 'some name')

Multiple criteria may be specified as comma separated; the effect is that they will be joined together using the and_() function:

session.query(MyClass).\
    filter(MyClass.name == 'some name', MyClass.id > 5)

The criterion is any SQL expression object applicable to the WHERE clause of a select. String expressions are coerced into SQL expression constructs via the text() construct.

See also

Query.filter_by() - filter on keyword expressions.

method sqlalchemy.orm.Query.filter_by(**kwargs)

Apply the given filtering criterion to a copy of this Query, using keyword expressions.

e.g.:

session.query(MyClass).filter_by(name = 'some name')

Multiple criteria may be specified as comma separated; the effect is that they will be joined together using the and_() function:

session.query(MyClass).\
    filter_by(name = 'some name', id = 5)

The keyword expressions are extracted from the primary entity of the query, or the last entity that was the target of a call to Query.join().

See also

Query.filter() - filter on SQL expressions.

method sqlalchemy.orm.Query.first()

Return the first result of this Query or None if the result doesn’t contain any row.

first() applies a limit of one within the generated SQL, so that only one primary entity row is generated on the server side (note this may consist of multiple result rows if join-loaded collections are present).

Calling Query.first() results in an execution of the underlying query.

method sqlalchemy.orm.Query.from_self(*entities)

return a Query that selects from this Query’s SELECT statement.

Deprecated since version 1.4: The Query.from_self() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. The new approach is to use the aliased() construct in conjunction with a subquery. See the section Selecting from the query itself as a subquery in the 2.0 migration notes for an example. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

Query.from_self() essentially turns the SELECT statement into a SELECT of itself. Given a query such as:

q = session.query(User).filter(User.name.like('e%'))

Given the Query.from_self() version:

q = session.query(User).filter(User.name.like('e%')).from_self()

This query renders as:

SELECT anon_1.user_id AS anon_1_user_id,
       anon_1.user_name AS anon_1_user_name
FROM (SELECT "user".id AS user_id, "user".name AS user_name
FROM "user"
WHERE "user".name LIKE :name_1) AS anon_1

There are lots of cases where Query.from_self() may be useful. A simple one is where above, we may want to apply a row LIMIT to the set of user objects we query against, and then apply additional joins against that row-limited set:

q = session.query(User).filter(User.name.like('e%')).\
    limit(5).from_self().\
    join(User.addresses).filter(Address.email.like('q%'))

The above query joins to the Address entity but only against the first five results of the User query:

SELECT anon_1.user_id AS anon_1_user_id,
       anon_1.user_name AS anon_1_user_name
FROM (SELECT "user".id AS user_id, "user".name AS user_name
FROM "user"
WHERE "user".name LIKE :name_1
 LIMIT :param_1) AS anon_1
JOIN address ON anon_1.user_id = address.user_id
WHERE address.email LIKE :email_1

Automatic Aliasing

Another key behavior of Query.from_self() is that it applies automatic aliasing to the entities inside the subquery, when they are referenced on the outside. Above, if we continue to refer to the User entity without any additional aliasing applied to it, those references will be in terms of the subquery:

q = session.query(User).filter(User.name.like('e%')).\
    limit(5).from_self().\
    join(User.addresses).filter(Address.email.like('q%')).\
    order_by(User.name)

The ORDER BY against User.name is aliased to be in terms of the inner subquery:

SELECT anon_1.user_id AS anon_1_user_id,
       anon_1.user_name AS anon_1_user_name
FROM (SELECT "user".id AS user_id, "user".name AS user_name
FROM "user"
WHERE "user".name LIKE :name_1
 LIMIT :param_1) AS anon_1
JOIN address ON anon_1.user_id = address.user_id
WHERE address.email LIKE :email_1 ORDER BY anon_1.user_name

The automatic aliasing feature only works in a limited way, for simple filters and orderings. More ambitious constructions such as referring to the entity in joins should prefer to use explicit subquery objects, typically making use of the Query.subquery() method to produce an explicit subquery object. Always test the structure of queries by viewing the SQL to ensure a particular structure does what’s expected!

Changing the Entities

Query.from_self() also includes the ability to modify what columns are being queried. In our example, we want User.id to be queried by the inner query, so that we can join to the Address entity on the outside, but we only wanted the outer query to return the Address.email column:

q = session.query(User).filter(User.name.like('e%')).\
    limit(5).from_self(Address.email).\
    join(User.addresses).filter(Address.email.like('q%'))

yielding:

SELECT address.email AS address_email
FROM (SELECT "user".id AS user_id, "user".name AS user_name
FROM "user"
WHERE "user".name LIKE :name_1
 LIMIT :param_1) AS anon_1
JOIN address ON anon_1.user_id = address.user_id
WHERE address.email LIKE :email_1

Looking out for Inner / Outer Columns

Keep in mind that when referring to columns that originate from inside the subquery, we need to ensure they are present in the columns clause of the subquery itself; this is an ordinary aspect of SQL. For example, if we wanted to load from a joined entity inside the subquery using contains_eager(), we need to add those columns. Below illustrates a join of Address to User, then a subquery, and then we’d like contains_eager() to access the User columns:

q = session.query(Address).join(Address.user).\
    filter(User.name.like('e%'))

q = q.add_entity(User).from_self().\
    options(contains_eager(Address.user))

We use Query.add_entity() above before we call Query.from_self() so that the User columns are present in the inner subquery, so that they are available to the contains_eager() modifier we are using on the outside, producing:

SELECT anon_1.address_id AS anon_1_address_id,
       anon_1.address_email AS anon_1_address_email,
       anon_1.address_user_id AS anon_1_address_user_id,
       anon_1.user_id AS anon_1_user_id,
       anon_1.user_name AS anon_1_user_name
FROM (
    SELECT address.id AS address_id,
    address.email AS address_email,
    address.user_id AS address_user_id,
    "user".id AS user_id,
    "user".name AS user_name
FROM address JOIN "user" ON "user".id = address.user_id
WHERE "user".name LIKE :name_1) AS anon_1

If we didn’t call add_entity(User), but still asked contains_eager() to load the User entity, it would be forced to add the table on the outside without the correct join criteria - note the anon1, "user" phrase at the end:

-- incorrect query
SELECT anon_1.address_id AS anon_1_address_id,
       anon_1.address_email AS anon_1_address_email,
       anon_1.address_user_id AS anon_1_address_user_id,
       "user".id AS user_id,
       "user".name AS user_name
FROM (
    SELECT address.id AS address_id,
    address.email AS address_email,
    address.user_id AS address_user_id
FROM address JOIN "user" ON "user".id = address.user_id
WHERE "user".name LIKE :name_1) AS anon_1, "user"
Parameters:

*entities – optional list of entities which will replace those being selected.

method sqlalchemy.orm.Query.from_statement(statement)

Execute the given SELECT statement and return results.

This method bypasses all internal statement compilation, and the statement is executed without modification.

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

See also

Using Textual SQL - usage examples in the ORM tutorial

method sqlalchemy.orm.Query.get(ident)

Return an instance based on the given primary key identifier, or None if not found.

Deprecated since version 1.4: The Query.get() method is considered legacy as of the 1.x series of SQLAlchemy and becomes a legacy construct in 2.0. The method is now available as Session.get() (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

E.g.:

my_user = session.query(User).get(5)

some_object = session.query(VersionedFoo).get((5, 10))

some_object = session.query(VersionedFoo).get(
    {"id": 5, "version_id": 10})

Query.get() is special in that it provides direct access to the identity map of the owning Session. If the given primary key identifier is present in the local identity map, the object is returned directly from this collection and no SQL is emitted, unless the object has been marked fully expired. If not present, a SELECT is performed in order to locate the object.

Query.get() also will perform a check if the object is present in the identity map and marked as expired - a SELECT is emitted to refresh the object as well as to ensure that the row is still present. If not, ObjectDeletedError is raised.

Query.get() is only used to return a single mapped instance, not multiple instances or individual column constructs, and strictly on a single primary key value. The originating Query must be constructed in this way, i.e. against a single mapped entity, with no additional filtering criterion. Loading options via Query.options() may be applied however, and will be used if the object is not yet locally present.

Parameters:

ident

A scalar, tuple, or dictionary representing the primary key. For a composite (e.g. multiple column) primary key, a tuple or dictionary should be passed.

For a single-column primary key, the scalar calling form is typically the most expedient. If the primary key of a row is the value “5”, the call looks like:

my_object = query.get(5)

The tuple form contains primary key values typically in the order in which they correspond to the mapped Table object’s primary key columns, or if the Mapper.primary_key configuration parameter were used, in the order used for that parameter. For example, if the primary key of a row is represented by the integer digits “5, 10” the call would look like:

my_object = query.get((5, 10))

The dictionary form should include as keys the mapped attribute names corresponding to each element of the primary key. If the mapped class has the attributes id, version_id as the attributes which store the object’s primary key value, the call would look like:

my_object = query.get({"id": 5, "version_id": 10})

New in version 1.3: the Query.get() method now optionally accepts a dictionary of attribute names to values in order to indicate a primary key identifier.

Returns:

The object instance, or None.

method sqlalchemy.orm.Query.get_execution_options()

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

New in version 1.3.

attribute sqlalchemy.orm.Query.get_label_style

Retrieve the current label style.

New in version 1.4.

method sqlalchemy.orm.Query.group_by(*clauses)

Apply one or more GROUP BY criterion to the query and return the newly resulting Query.

All existing GROUP BY settings can be suppressed by passing None - this will suppress any GROUP BY configured on mappers as well.

See also

These sections describe GROUP BY in terms of 2.0 style invocation but apply to Query as well:

Aggregate functions with GROUP BY / HAVING - in the SQLAlchemy 1.4 / 2.0 Tutorial

Ordering or Grouping by a Label - in the SQLAlchemy 1.4 / 2.0 Tutorial

method sqlalchemy.orm.Query.having(criterion)

Apply a HAVING criterion to the query and return the newly resulting Query.

Query.having() is used in conjunction with Query.group_by().

HAVING criterion makes it possible to use filters on aggregate functions like COUNT, SUM, AVG, MAX, and MIN, eg.:

q = session.query(User.id).\
            join(User.addresses).\
            group_by(User.id).\
            having(func.count(Address.id) > 2)
method sqlalchemy.orm.Query.instances(result_proxy, context=None)

Return an ORM result given a CursorResult and QueryContext.

method sqlalchemy.orm.Query.intersect(*q)

Produce an INTERSECT of this Query against one or more queries.

Works the same way as Query.union(). See that method for usage examples.

method sqlalchemy.orm.Query.intersect_all(*q)

Produce an INTERSECT ALL of this Query against one or more queries.

Works the same way as Query.union(). See that method for usage examples.

attribute sqlalchemy.orm.Query.is_single_entity

Indicates if this Query returns tuples or single entities.

Returns True if this query returns a single entity for each instance in its result list, and False if this query returns a tuple of entities for each result.

New in version 1.3.11.

method sqlalchemy.orm.Query.join(target, *props, **kwargs)

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

Simple Relationship Joins

Consider a mapping between two classes User and Address, with a relationship User.addresses representing a collection of Address objects associated with each User. The most common usage of Query.join() is to create a JOIN along this relationship, using the User.addresses attribute as an indicator for how this should occur:

q = session.query(User).join(User.addresses)

Where above, the call to Query.join() along User.addresses will result in SQL approximately equivalent to:

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

In the above example we refer to User.addresses as passed to Query.join() as the “on clause”, that is, it indicates how the “ON” portion of the JOIN should be constructed.

To construct a chain of joins, multiple Query.join() calls may be used. The relationship-bound attribute implies both the left and right side of the join at once:

q = session.query(User).\
        join(User.orders).\
        join(Order.items).\
        join(Item.keywords)

Note

as seen in the above example, the order in which each call to the join() method occurs is important. Query would not, for example, know how to join correctly if we were to specify User, then Item, then Order, in our chain of joins; in such a case, depending on the arguments passed, it may raise an error that it doesn’t know how to join, or it may produce invalid SQL in which case the database will raise an error. In correct practice, the Query.join() method is invoked in such a way that lines up with how we would want the JOIN clauses in SQL to be rendered, and each call should represent a clear link from what precedes it.

Joins to a Target Entity or Selectable

A second form of Query.join() allows any mapped entity or core selectable construct as a target. In this usage, Query.join() will attempt to create a JOIN along the natural foreign key relationship between two entities:

q = session.query(User).join(Address)

In the above calling form, Query.join() is called upon to create the “on clause” automatically for us. This calling form will ultimately raise an error if either there are no foreign keys between the two entities, or if there are multiple foreign key linkages between the target entity and the entity or entities already present on the left side such that creating a join requires more information. Note that when indicating a join to a target without any ON clause, ORM configured relationships are not taken into account.

Joins to a Target with an ON Clause

The third calling form allows both the target entity as well as the ON clause to be passed explicitly. A example that includes a SQL expression as the ON clause is as follows:

q = session.query(User).join(Address, User.id==Address.user_id)

The above form may also use a relationship-bound attribute as the ON clause as well:

q = session.query(User).join(Address, User.addresses)

The above syntax can be useful for the case where we wish to join to an alias of a particular target entity. If we wanted to join to Address twice, it could be achieved using two aliases set up using the aliased() function:

a1 = aliased(Address)
a2 = aliased(Address)

q = session.query(User).\
        join(a1, User.addresses).\
        join(a2, User.addresses).\
        filter(a1.email_address=='ed@foo.com').\
        filter(a2.email_address=='ed@bar.com')

The relationship-bound calling form can also specify a target entity using the PropComparator.of_type() method; a query equivalent to the one above would be:

a1 = aliased(Address)
a2 = aliased(Address)

q = session.query(User).\
        join(User.addresses.of_type(a1)).\
        join(User.addresses.of_type(a2)).\
        filter(a1.email_address == 'ed@foo.com').\
        filter(a2.email_address == 'ed@bar.com')

Augmenting Built-in ON Clauses

As a substitute for providing a full custom ON condition for an existing relationship, the PropComparator.and_() function may be applied to a relationship attribute to augment additional criteria into the ON clause; the additional criteria will be combined with the default criteria using AND:

q = session.query(User).join(
    User.addresses.and_(Address.email_address != 'foo@bar.com')
)

New in version 1.4.

Joining to Tables and Subqueries

The target of a join may also be any table or SELECT statement, which may be related to a target entity or not. Use the appropriate .subquery() method in order to make a subquery out of a query:

subq = session.query(Address).\
    filter(Address.email_address == 'ed@foo.com').\
    subquery()


q = session.query(User).join(
    subq, User.id == subq.c.user_id
)

Joining to a subquery in terms of a specific relationship and/or target entity may be achieved by linking the subquery to the entity using aliased():

subq = session.query(Address).\
    filter(Address.email_address == 'ed@foo.com').\
    subquery()

address_subq = aliased(Address, subq)

q = session.query(User).join(
    User.addresses.of_type(address_subq)
)

Controlling what to Join From

In cases where the left side of the current state of Query is not in line with what we want to join from, the Query.select_from() method may be used:

q = session.query(Address).select_from(User).\
                join(User.addresses).\
                filter(User.name == 'ed')

Which will produce SQL similar to:

SELECT address.* FROM user
    JOIN address ON user.id=address.user_id
    WHERE user.name = :name_1

Legacy Features of Query.join()

Deprecated since version 1.4: The following features are deprecated and will be removed in SQLAlchemy 2.0.

The Query.join() method currently supports several usage patterns and arguments that are considered to be legacy as of SQLAlchemy 1.3. A deprecation path will follow in the 1.4 series for the following features:

  • Joining on relationship names rather than attributes:

    session.query(User).join("addresses")

    Why it’s legacy: the string name does not provide enough context for Query.join() to always know what is desired, notably in that there is no indication of what the left side of the join should be. This gives rise to flags like from_joinpoint as well as the ability to place several join clauses in a single Query.join() call which don’t solve the problem fully while also adding new calling styles that are unnecessary and expensive to accommodate internally.

    Modern calling pattern: Use the actual relationship, e.g. User.addresses in the above case:

    session.query(User).join(User.addresses)
  • Automatic aliasing with the aliased=True flag:

    session.query(Node).join(Node.children, aliased=True).\
        filter(Node.name == 'some name')

    Why it’s legacy: the automatic aliasing feature of Query is intensely complicated, both in its internal implementation as well as in its observed behavior, and is almost never used. It is difficult to know upon inspection where and when its aliasing of a target entity, Node in the above case, will be applied and when it won’t, and additionally the feature has to use very elaborate heuristics to achieve this implicit behavior.

    Modern calling pattern: Use the aliased() construct explicitly:

    from sqlalchemy.orm import aliased
    
    n1 = aliased(Node)
    
    session.query(Node).join(Node.children.of_type(n1)).\
        filter(n1.name == 'some name')
  • Multiple joins in one call:

    session.query(User).join("orders", "items")
    
    session.query(User).join(User.orders, Order.items)
    
    session.query(User).join(
        (Order, User.orders),
        (Item, Item.order_id == Order.id)
    )
    
    session.query(User).join(Order, Item)
    
    # ... and several more forms actually

    Why it’s legacy: being able to chain multiple ON clauses in one call to Query.join() is yet another attempt to solve the problem of being able to specify what entity to join from, and is the source of a large variety of potential calling patterns that are internally expensive and complicated to parse and accommodate.

    Modern calling pattern: Use relationship-bound attributes or SQL-oriented ON clauses within separate calls, so that each call to Query.join() knows what the left side should be:

    session.query(User).join(User.orders).join(
        Item, Item.order_id == Order.id)
Parameters:
  • *props – Incoming arguments for Query.join(), the props collection in modern use should be considered to be a one or two argument form, either as a single “target” entity or ORM attribute-bound relationship, or as a target entity plus an “on clause” which may be a SQL expression or ORM attribute-bound relationship.

  • isouter=False – If True, the join used will be a left outer join, just as if the Query.outerjoin() method were called.

  • full=False

    render FULL OUTER JOIN; implies isouter.

    New in version 1.1.

  • from_joinpoint=False

    When using aliased=True, a setting of True here will cause the join to be from the most recent joined target, rather than starting back from the original FROM clauses of the query.

    Note

    This flag is considered legacy.

  • aliased=False

    If True, indicate that the JOIN target should be anonymously aliased. Subsequent calls to Query.filter() and similar will adapt the incoming criterion to the target alias, until Query.reset_joinpoint() is called.

    Note

    This flag is considered legacy.

See also

Querying with Joins in the ORM tutorial.

Mapping Class Inheritance Hierarchies for details on how Query.join() is used for inheritance relationships.

join() - a standalone ORM-level join function, used internally by Query.join(), which in previous SQLAlchemy versions was the primary ORM-level joining interface.

method sqlalchemy.orm.Query.label(name)

Return the full SELECT statement represented by this Query, converted to a scalar subquery with a label of the given name.

Analogous to SelectBase.label().

attribute sqlalchemy.orm.Query.lazy_loaded_from

An InstanceState that is using this Query for a lazy load operation.

Deprecated since version 1.4: This attribute should be viewed via the ORMExecuteState.lazy_loaded_from attribute, within the context of the SessionEvents.do_orm_execute() event.

method sqlalchemy.orm.Query.limit(limit)

Apply a LIMIT to the query and return the newly resulting Query.

classmethod sqlalchemy.orm.Query.memoized_instancemethod(fn)

inherited from the HasMemoized.memoized_instancemethod() method of HasMemoized

Decorate a method memoize its return value.

method sqlalchemy.orm.Query.merge_result(iterator, load=True)

Merge a result into this Query object’s Session.

Deprecated since version 1.4: The Query.merge_result() method is considered legacy as of the 1.x series of SQLAlchemy and becomes a legacy construct in 2.0. The method is superseded by the merge_frozen_result() function. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

Given an iterator returned by a Query of the same structure as this one, return an identical iterator of results, with all mapped instances merged into the session using Session.merge(). This is an optimized method which will merge all mapped instances, preserving the structure of the result rows and unmapped columns with less method overhead than that of calling Session.merge() explicitly for each value.

The structure of the results is determined based on the column list of this Query - if these do not correspond, unchecked errors will occur.

The ‘load’ argument is the same as that of Session.merge().

For an example of how Query.merge_result() is used, see the source code for the example Dogpile Caching, where Query.merge_result() is used to efficiently restore state from a cache back into a target Session.

method sqlalchemy.orm.Query.offset(offset)

Apply an OFFSET to the query and return the newly resulting Query.

method sqlalchemy.orm.Query.one()

Return exactly one result or raise an exception.

Raises sqlalchemy.orm.exc.NoResultFound if the query selects no rows. Raises sqlalchemy.orm.exc.MultipleResultsFound if multiple object identities are returned, or if multiple rows are returned for a query that returns only scalar values as opposed to full identity-mapped entities.

Calling one() results in an execution of the underlying query.

method sqlalchemy.orm.Query.one_or_none()

Return at most one result or raise an exception.

Returns None if the query selects no rows. Raises sqlalchemy.orm.exc.MultipleResultsFound if multiple object identities are returned, or if multiple rows are returned for a query that returns only scalar values as opposed to full identity-mapped entities.

Calling Query.one_or_none() results in an execution of the underlying query.

New in version 1.0.9: Added Query.one_or_none()

method sqlalchemy.orm.Query.only_return_tuples(value)

When set to True, the query results will always be a tuple.

This is specifically for single element queries. The default is False.

New in version 1.2.5.

method sqlalchemy.orm.Query.options(*args)

Return a new Query object, applying the given list of mapper options.

Most supplied options regard changing how column- and relationship-mapped attributes are loaded.

method sqlalchemy.orm.Query.order_by(*clauses)

Apply one or more ORDER BY criteria to the query and return the newly resulting Query.

e.g.:

q = session.query(Entity).order_by(Entity.id, Entity.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
q = q.order_by(None).order_by(new_col)

See also

These sections describe ORDER BY in terms of 2.0 style invocation but apply to Query as well:

ORDER BY - in the SQLAlchemy 1.4 / 2.0 Tutorial

Ordering or Grouping by a Label - in the SQLAlchemy 1.4 / 2.0 Tutorial

method sqlalchemy.orm.Query.outerjoin(target, *props, **kwargs)

Create a left outer join against this Query object’s criterion and apply generatively, returning the newly resulting Query.

Usage is the same as the join() method.

method sqlalchemy.orm.Query.params(*args, **kwargs)

Add values for bind parameters which may have been specified in filter().

Parameters may be specified using **kwargs, or optionally a single dictionary as the first positional argument. The reason for both is that **kwargs is convenient, however some parameter dictionaries contain unicode keys in which case **kwargs cannot be used.

method sqlalchemy.orm.Query.populate_existing()

Return a Query that will expire and refresh all instances as they are loaded, or reused from the current Session.

As of SQLAlchemy 1.4, the Query.populate_existing() method is equivalent to using the populate_existing execution option at the ORM level. See the section Populate Existing for further background on this option.

method sqlalchemy.orm.Query.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.orm.Query.reset_joinpoint()

Return a new Query, where the “join point” has been reset back to the base FROM entities of the query.

This method is usually used in conjunction with the aliased=True feature of the Query.join() method. See the example in Query.join() for how this is used.

method sqlalchemy.orm.Query.scalar()

Return the first element of the first result or None if no rows present. If multiple rows are returned, raises MultipleResultsFound.

>>> session.query(Item).scalar()
<Item>
>>> session.query(Item.id).scalar()
1
>>> session.query(Item.id).filter(Item.id < 0).scalar()
None
>>> session.query(Item.id, Item.name).scalar()
1
>>> session.query(func.count(Parent.id)).scalar()
20

This results in an execution of the underlying query.

method sqlalchemy.orm.Query.scalar_subquery()

Return the full SELECT statement represented by this Query, converted to a scalar subquery.

Analogous to SelectBase.scalar_subquery().

Changed in version 1.4: The Query.scalar_subquery() method replaces the Query.as_scalar() method.

method sqlalchemy.orm.Query.select_entity_from(from_obj)

Set the FROM clause of this Query to a core selectable, applying it as a replacement FROM clause for corresponding mapped entities.

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

The Query.select_entity_from() method supplies an alternative approach to the use case of applying an aliased() construct explicitly throughout a query. Instead of referring to the aliased() construct explicitly, Query.select_entity_from() automatically adapts all occurrences of the entity to the target selectable.

Given a case for aliased() such as selecting User objects from a SELECT statement:

select_stmt = select(User).where(User.id == 7)
user_alias = aliased(User, select_stmt)

q = session.query(user_alias).\
    filter(user_alias.name == 'ed')

Above, we apply the user_alias object explicitly throughout the query. When it’s not feasible for user_alias to be referenced explicitly in many places, Query.select_entity_from() may be used at the start of the query to adapt the existing User entity:

q = session.query(User).\
    select_entity_from(select_stmt.subquery()).\
    filter(User.name == 'ed')

Above, the generated SQL will show that the User entity is adapted to our statement, even in the case of the WHERE clause:

SELECT anon_1.id AS anon_1_id, anon_1.name AS anon_1_name
FROM (SELECT "user".id AS id, "user".name AS name
FROM "user"
WHERE "user".id = :id_1) AS anon_1
WHERE anon_1.name = :name_1

The Query.select_entity_from() method is similar to the Query.select_from() method, in that it sets the FROM clause of the query. The difference is that it additionally applies adaptation to the other parts of the query that refer to the primary entity. If above we had used Query.select_from() instead, the SQL generated would have been:

-- uses plain select_from(), not select_entity_from()
SELECT "user".id AS user_id, "user".name AS user_name
FROM "user", (SELECT "user".id AS id, "user".name AS name
FROM "user"
WHERE "user".id = :id_1) AS anon_1
WHERE "user".name = :name_1

To supply textual SQL to the Query.select_entity_from() method, we can make use of the text() construct. However, the text() construct needs to be aligned with the columns of our entity, which is achieved by making use of the TextClause.columns() method:

text_stmt = text("select id, name from user").columns(
    User.id, User.name).subquery()
q = session.query(User).select_entity_from(text_stmt)

Query.select_entity_from() itself accepts an aliased() object, so that the special options of aliased() such as aliased.adapt_on_names may be used within the scope of the Query.select_entity_from() method’s adaptation services. Suppose a view user_view also returns rows from user. If we reflect this view into a Table, this view has no relationship to the Table to which we are mapped, however we can use name matching to select from it:

user_view = Table('user_view', metadata,
                  autoload_with=engine)
user_view_alias = aliased(
    User, user_view, adapt_on_names=True)
q = session.query(User).\
    select_entity_from(user_view_alias).\
    order_by(User.name)

Changed in version 1.1.7: The Query.select_entity_from() method now accepts an aliased() object as an alternative to a FromClause object.

Parameters:

from_obj – a FromClause object that will replace the FROM clause of this Query. It also may be an instance of aliased().

method sqlalchemy.orm.Query.select_from(*from_obj)

Set the FROM clause of this Query explicitly.

Query.select_from() is often used in conjunction with Query.join() in order to control which entity is selected from on the “left” side of the join.

The entity or selectable object here effectively replaces the “left edge” of any calls to Query.join(), when no joinpoint is otherwise established - usually, the default “join point” is the leftmost entity in the Query object’s list of entities to be selected.

A typical example:

q = session.query(Address).select_from(User).\
    join(User.addresses).\
    filter(User.name == 'ed')

Which produces SQL equivalent to:

SELECT address.* FROM user
JOIN address ON user.id=address.user_id
WHERE user.name = :name_1
Parameters:

*from_obj – collection of one or more entities to apply to the FROM clause. Entities can be mapped classes, AliasedClass objects, Mapper objects as well as core FromClause elements like subqueries.

Changed in version 0.9: This method no longer applies the given FROM object to be the selectable from which matching entities select from; the select_entity_from() method now accomplishes this. See that method for a description of this behavior.

attribute sqlalchemy.orm.Query.selectable

Return the Select object emitted by this Query.

Used for inspect() compatibility, this is equivalent to:

query.enable_eagerloads(False).with_labels().statement
method sqlalchemy.orm.Query.set_label_style(style)

Apply column labels to the return value of Query.statement.

Indicates that this Query’s statement accessor should return a SELECT statement that applies labels to all columns in the form <tablename>_<columnname>; this is commonly used to disambiguate columns from multiple tables which have the same name.

When the Query actually issues SQL to load rows, it always uses column labeling.

Note

The Query.set_label_style() method only applies the output of Query.statement, and not to any of the result-row invoking systems of Query itself, e.g. Query.first(), Query.all(), etc. To execute a query using Query.set_label_style(), invoke the Query.statement using Session.execute():

result = session.execute(
    query
    .set_label_style(LABEL_STYLE_TABLENAME_PLUS_COL)
    .statement
)

New in version 1.4.

method sqlalchemy.orm.Query.slice(start, stop)

Computes the “slice” of the Query represented by the given indices and returns the resulting Query.

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,

session.query(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)
attribute sqlalchemy.orm.Query.statement

The full SELECT statement represented by this Query.

The statement by default will not have disambiguating labels applied to the construct unless with_labels(True) is called first.

method sqlalchemy.orm.Query.subquery(name=None, with_labels=False, reduce_columns=False)

Return the full SELECT statement represented by this Query, embedded within an Alias.

Eager JOIN generation within the query is disabled.

Parameters:
  • name – string name to be assigned as the alias; this is passed through to FromClause.alias(). If None, a name will be deterministically generated at compile time.

  • with_labels – if True, with_labels() will be called on the Query first to apply table-qualified labels to all columns.

  • reduce_columns – if True, Select.reduce_columns() will be called on the resulting select() construct, to remove same-named columns where one also refers to the other via foreign key or WHERE clause equivalence.

method sqlalchemy.orm.Query.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.orm.Query.union(*q)

Produce a UNION of this Query against one or more queries.

e.g.:

q1 = sess.query(SomeClass).filter(SomeClass.foo=='bar')
q2 = sess.query(SomeClass).filter(SomeClass.bar=='foo')

q3 = q1.union(q2)

The method accepts multiple Query objects so as to control the level of nesting. A series of union() calls such as:

x.union(y).union(z).all()

will nest on each union(), and produces:

SELECT * FROM (SELECT * FROM (SELECT * FROM X UNION
                SELECT * FROM y) UNION SELECT * FROM Z)

Whereas:

x.union(y, z).all()

produces:

SELECT * FROM (SELECT * FROM X UNION SELECT * FROM y UNION
                SELECT * FROM Z)

Note that many database backends do not allow ORDER BY to be rendered on a query called within UNION, EXCEPT, etc. To disable all ORDER BY clauses including those configured on mappers, issue query.order_by(None) - the resulting Query object will not render ORDER BY within its SELECT statement.

method sqlalchemy.orm.Query.union_all(*q)

Produce a UNION ALL of this Query against one or more queries.

Works the same way as Query.union(). See that method for usage examples.

method sqlalchemy.orm.Query.update(values, synchronize_session='evaluate', update_args=None)

Perform an UPDATE with an arbitrary WHERE clause.

Updates rows matched by this query in the database.

E.g.:

sess.query(User).filter(User.age == 25).\
    update({User.age: User.age - 10}, synchronize_session=False)

sess.query(User).filter(User.age == 25).\
    update({"age": User.age - 10}, synchronize_session='evaluate')

Warning

See the section UPDATE and DELETE with arbitrary WHERE clause for important caveats and warnings, including limitations when using arbitrary UPDATE and DELETE with mapper inheritance configurations.

Parameters:
  • values – a dictionary with attributes names, or alternatively mapped attributes or SQL expressions, as keys, and literal values or sql expressions as values. If parameter-ordered mode is desired, the values can be passed as a list of 2-tuples; this requires that the update.preserve_parameter_order flag is passed to the Query.update.update_args dictionary as well.

  • synchronize_session – chooses the strategy to update the attributes on objects in the session. See the section UPDATE and DELETE with arbitrary WHERE clause for a discussion of these strategies.

  • update_args – Optional dictionary, if present will be passed to the underlying update() construct as the **kw for the object. May be used to pass dialect-specific arguments such as mysql_limit, as well as other special arguments such as update.preserve_parameter_order.

Returns:

the count of rows matched as returned by the database’s “row count” feature.

method sqlalchemy.orm.Query.value(column)

Return a scalar result corresponding to the given column expression.

Deprecated since version 1.4: Query.value() is deprecated and will be removed in a future release. Please use Query.with_entities() in combination with Query.scalar()

method sqlalchemy.orm.Query.values(*columns)

Return an iterator yielding result tuples corresponding to the given list of columns

Deprecated since version 1.4: Query.values() is deprecated and will be removed in a future release. Please use Query.with_entities()

method sqlalchemy.orm.Query.where(*criterion)

A synonym for Query.filter().

New in version 1.4.

attribute sqlalchemy.orm.Query.whereclause

A readonly attribute which returns the current WHERE criterion for this Query.

This returned value is a SQL expression construct, or None if no criterion has been established.

method sqlalchemy.orm.Query.with_entities(*entities)

Return a new Query replacing the SELECT list with the given entities.

e.g.:

# Users, filtered on some arbitrary criterion
# and then ordered by related email address
q = session.query(User).\
            join(User.address).\
            filter(User.name.like('%ed%')).\
            order_by(Address.email)

# given *only* User.id==5, Address.email, and 'q', what
# would the *next* User in the result be ?
subq = q.with_entities(Address.email).\
            order_by(None).\
            filter(User.id==5).\
            subquery()
q = q.join((subq, subq.c.email < Address.email)).\
            limit(1)
method sqlalchemy.orm.Query.with_for_update(read=False, nowait=False, of=None, skip_locked=False, key_share=False)

return a new Query with the specified options for the FOR UPDATE clause.

The behavior of this method is identical to that of GenerativeSelect.with_for_update(). When called with no arguments, the resulting SELECT statement will have a FOR UPDATE clause appended. When additional arguments are specified, backend-specific options such as FOR UPDATE NOWAIT or LOCK IN SHARE MODE can take effect.

E.g.:

q = sess.query(User).populate_existing().with_for_update(nowait=True, of=User)

The above query on a PostgreSQL backend will render like:

SELECT users.id AS users_id FROM users FOR UPDATE OF users NOWAIT

Warning

Using with_for_update in the context of eager loading relationships is not officially supported or recommended by SQLAlchemy and may not work with certain queries on various database backends. When with_for_update is successfully used with a query that involves joinedload(), SQLAlchemy will attempt to emit SQL that locks all involved tables.

Note

It is generally a good idea to combine the use of the Query.populate_existing() method when using the Query.with_for_update() method. The purpose of Query.populate_existing() is to force all the data read from the SELECT to be populated into the ORM objects returned, even if these objects are already in the identity map.

See also

GenerativeSelect.with_for_update() - Core level method with full argument and behavioral description.

Query.populate_existing() - overwrites attributes of objects already loaded in the identity map.

method sqlalchemy.orm.Query.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.orm.Query.with_labels()

Deprecated since version 1.4: The Query.with_labels() and Query.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.orm.Query.with_parent(instance, property=None, from_entity=None)

Add filtering criterion that relates the given instance to a child object or collection, using its attribute state as well as an established relationship() configuration.

Deprecated since version 1.4: The Query.with_parent() method is considered legacy as of the 1.x series of SQLAlchemy and becomes a legacy construct in 2.0. Use the with_parent() standalone construct. (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

The method uses the with_parent() function to generate the clause, the result of which is passed to Query.filter().

Parameters are the same as with_parent(), with the exception that the given property can be None, in which case a search is performed against this Query object’s target mapper.

Parameters:
  • instance – An instance which has some relationship().

  • property – String property name, or class-bound attribute, which indicates what relationship from the instance should be used to reconcile the parent/child relationship.

  • from_entity – Entity in which to consider as the left side. This defaults to the “zero” entity of the Query itself.

method sqlalchemy.orm.Query.with_polymorphic(cls_or_mappers, selectable=None, polymorphic_on=None)

Load columns for inheriting classes.

Deprecated since version 1.4: The Query.with_polymorphic() method is considered legacy as of the 1.x series of SQLAlchemy and will be removed in 2.0. Use the orm.with_polymorphic() standalone function (Background on SQLAlchemy 2.0 at: Migrating to SQLAlchemy 2.0)

This is a legacy method which is replaced by the with_polymorphic() function.

Warning

The Query.with_polymorphic() method does not support 1.4/2.0 style features including with_loader_criteria(). Please migrate code to use with_polymorphic().

Query.with_polymorphic() applies transformations to the “main” mapped class represented by this Query. The “main” mapped class here means the Query object’s first argument is a full class, i.e. session.query(SomeClass). These transformations allow additional tables to be present in the FROM clause so that columns for a joined-inheritance subclass are available in the query, both for the purposes of load-time efficiency as well as the ability to use these columns at query time.

See also

Using with_polymorphic - illustrates current patterns

method sqlalchemy.orm.Query.with_session(session)

Return a Query that will use the given Session.

While the Query object is normally instantiated using the Session.query() method, it is legal to build the Query directly without necessarily using a Session. Such a Query object, or any Query already associated with a different Session, can produce a new Query object associated with a target session using this method:

from sqlalchemy.orm import Query

query = Query([MyClass]).filter(MyClass.id == 5)

result = query.with_session(my_session).one()
method sqlalchemy.orm.Query.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

method sqlalchemy.orm.Query.with_transformation(fn)

Return a new Query object transformed by the given function.

E.g.:

def filter_something(criterion):
    def transform(q):
        return q.filter(criterion)
    return transform

q = q.with_transformation(filter_something(x==5))

This allows ad-hoc recipes to be created for Query objects. See the example at Building Transformers.

method sqlalchemy.orm.Query.yield_per(count)

Yield only count rows at a time.

The purpose of this method is when fetching very large result sets (> 10K rows), to batch results in sub-collections and yield them out partially, so that the Python interpreter doesn’t need to declare very large areas of memory which is both time consuming and leads to excessive memory use. The performance from fetching hundreds of thousands of rows can often double when a suitable yield-per setting (e.g. approximately 1000) is used, even with DBAPIs that buffer rows (which are most).

As of SQLAlchemy 1.4, the Query.yield_per() method is equivalent to using the yield_per execution option at the ORM level. See the section Fetching Large Result Sets with Yield Per for further background on this option.

ORM-Specific Query Constructs

Object Name Description

aliased(element[, alias, name, flat, ...])

Produce an alias of the given element, usually an AliasedClass instance.

AliasedClass

Represents an “aliased” form of a mapped class for usage with Query.

AliasedInsp

Provide an inspection interface for an AliasedClass object.

Bundle

A grouping of SQL expressions that are returned by a Query under one namespace.

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

Produce an inner join between left and right clauses.

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

Produce a left outer join between left and right clauses.

with_loader_criteria(entity_or_base, where_criteria[, loader_only, include_aliases, ...])

Add additional WHERE criteria to the load for all occurrences of a particular entity.

with_parent(instance, prop[, from_entity])

Create filtering criterion that relates this query’s primary entity to the given related instance, using established relationship() configuration.

function sqlalchemy.orm.aliased(element, alias=None, name=None, flat=False, adapt_on_names=False)

Produce an alias of the given element, usually an AliasedClass instance.

E.g.:

my_alias = aliased(MyClass)

session.query(MyClass, my_alias).filter(MyClass.id > my_alias.id)

The aliased() function is used to create an ad-hoc mapping of a mapped class to a new selectable. By default, a selectable is generated from the normally mapped selectable (typically a Table ) using the FromClause.alias() method. However, aliased() can also be used to link the class to a new select() statement. Also, the with_polymorphic() function is a variant of aliased() that is intended to specify a so-called “polymorphic selectable”, that corresponds to the union of several joined-inheritance subclasses at once.

For convenience, the aliased() function also accepts plain FromClause constructs, such as a Table or select() construct. In those cases, the FromClause.alias() method is called on the object and the new Alias object returned. The returned Alias is not ORM-mapped in this case.

Parameters:
  • element – element to be aliased. Is normally a mapped class, but for convenience can also be a FromClause element.

  • alias – Optional selectable unit to map the element to. This is usually used to link the object to a subquery, and should be an aliased select construct as one would produce from the Query.subquery() method or the Select.subquery() or Select.alias() methods of the select() construct.

  • name – optional string name to use for the alias, if not specified by the alias parameter. The name, among other things, forms the attribute name that will be accessible via tuples returned by a Query object. Not supported when creating aliases of Join objects.

  • flat – Boolean, will be passed through to the FromClause.alias() call so that aliases of Join objects will alias the individual tables inside the join, rather than creating a subquery. This is generally supported by all modern databases with regards to right-nested joins and generally produces more efficient queries.

  • adapt_on_names

    if True, more liberal “matching” will be used when mapping the mapped columns of the ORM entity to those of the given selectable - a name-based match will be performed if the given selectable doesn’t otherwise have a column that corresponds to one on the entity. The use case for this is when associating an entity with some derived selectable such as one that uses aggregate functions:

    class UnitPrice(Base):
        __tablename__ = 'unit_price'
        ...
        unit_id = Column(Integer)
        price = Column(Numeric)
    
    aggregated_unit_price = Session.query(
                                func.sum(UnitPrice.price).label('price')
                            ).group_by(UnitPrice.unit_id).subquery()
    
    aggregated_unit_price = aliased(UnitPrice,
                alias=aggregated_unit_price, adapt_on_names=True)

    Above, functions on aggregated_unit_price which refer to .price will return the func.sum(UnitPrice.price).label('price') column, as it is matched on the name “price”. Ordinarily, the “price” function wouldn’t have any “column correspondence” to the actual UnitPrice.price column as it is not a proxy of the original.

class sqlalchemy.orm.util.AliasedClass(mapped_class_or_ac, alias=None, name=None, flat=False, adapt_on_names=False, with_polymorphic_mappers=(), with_polymorphic_discriminator=None, base_alias=None, use_mapper_path=False, represents_outer_join=False)

Represents an “aliased” form of a mapped class for usage with Query.

The ORM equivalent of a alias() construct, this object mimics the mapped class using a __getattr__ scheme and maintains a reference to a real Alias object.

A primary purpose of AliasedClass is to serve as an alternate within a SQL statement generated by the ORM, such that an existing mapped entity can be used in multiple contexts. A simple example:

# find all pairs of users with the same name
user_alias = aliased(User)
session.query(User, user_alias).\
                join((user_alias, User.id > user_alias.id)).\
                filter(User.name == user_alias.name)

AliasedClass is also capable of mapping an existing mapped class to an entirely new selectable, provided this selectable is column- compatible with the existing mapped selectable, and it can also be configured in a mapping as the target of a relationship(). See the links below for examples.

The AliasedClass object is constructed typically using the aliased() function. It also is produced with additional configuration when using the with_polymorphic() function.

The resulting object is an instance of AliasedClass. This object implements an attribute scheme which produces the same attribute and method interface as the original mapped class, allowing AliasedClass to be compatible with any attribute technique which works on the original class, including hybrid attributes (see Hybrid Attributes).

The AliasedClass can be inspected for its underlying Mapper, aliased selectable, and other information using inspect():

from sqlalchemy import inspect
my_alias = aliased(MyClass)
insp = inspect(my_alias)

The resulting inspection object is an instance of AliasedInsp.

class sqlalchemy.orm.util.AliasedInsp(entity, inspected, selectable, name, with_polymorphic_mappers, polymorphic_on, _base_alias, _use_mapper_path, adapt_on_names, represents_outer_join, nest_adapters)

Provide an inspection interface for an AliasedClass object.

The AliasedInsp object is returned given an AliasedClass using the inspect() function:

from sqlalchemy import inspect
from sqlalchemy.orm import aliased

my_alias = aliased(MyMappedClass)
insp = inspect(my_alias)

Attributes on AliasedInsp include:

  • entity - the AliasedClass represented.

  • mapper - the Mapper mapping the underlying class.

  • selectable - the Alias construct which ultimately represents an aliased Table or Select construct.

  • name - the name of the alias. Also is used as the attribute name when returned in a result tuple from Query.

  • with_polymorphic_mappers - collection of Mapper objects indicating all those mappers expressed in the select construct for the AliasedClass.

  • polymorphic_on - an alternate column or SQL expression which will be used as the “discriminator” for a polymorphic load.

Class signature

class sqlalchemy.orm.AliasedInsp (sqlalchemy.orm.ORMEntityColumnsClauseRole, sqlalchemy.orm.ORMFromClauseRole, sqlalchemy.sql.traversals.MemoizedHasCacheKey, sqlalchemy.orm.base.InspectionAttr)

class sqlalchemy.orm.Bundle(name, *exprs, **kw)

A grouping of SQL expressions that are returned by a Query under one namespace.

The Bundle essentially allows nesting of the tuple-based results returned by a column-oriented Query object. It also is extensible via simple subclassing, where the primary capability to override is that of how the set of expressions should be returned, allowing post-processing as well as custom return types, without involving ORM identity-mapped classes.

New in version 0.9.0.

See also

Column Bundles

Class signature

class sqlalchemy.orm.Bundle (sqlalchemy.orm.ORMColumnsClauseRole, sqlalchemy.sql.annotation.SupportsCloneAnnotations, sqlalchemy.sql.traversals.MemoizedHasCacheKey, sqlalchemy.orm.base.InspectionAttr)

method sqlalchemy.orm.Bundle.__init__(name, *exprs, **kw)

Construct a new Bundle.

e.g.:

bn = Bundle("mybundle", MyClass.x, MyClass.y)

for row in session.query(bn).filter(
        bn.c.x == 5).filter(bn.c.y == 4):
    print(row.mybundle.x, row.mybundle.y)
Parameters:
  • name – name of the bundle.

  • *exprs – columns or SQL expressions comprising the bundle.

  • single_entity=False – if True, rows for this Bundle can be returned as a “single entity” outside of any enclosing tuple in the same manner as a mapped entity.

attribute sqlalchemy.orm.Bundle.c = None

An alias for Bundle.columns.

attribute sqlalchemy.orm.Bundle.columns = None

A namespace of SQL expressions referred to by this Bundle.

e.g.:

bn = Bundle("mybundle", MyClass.x, MyClass.y)

q = sess.query(bn).filter(bn.c.x == 5)

Nesting of bundles is also supported:

b1 = Bundle("b1",
        Bundle('b2', MyClass.a, MyClass.b),
        Bundle('b3', MyClass.x, MyClass.y)
    )

q = sess.query(b1).filter(
    b1.c.b2.c.a == 5).filter(b1.c.b3.c.y == 9)

See also

Bundle.c

method sqlalchemy.orm.Bundle.create_row_processor(query, procs, labels)

Produce the “row processing” function for this Bundle.

May be overridden by subclasses.

See also

Column Bundles - includes an example of subclassing.

attribute sqlalchemy.orm.Bundle.is_aliased_class = False

True if this object is an instance of AliasedClass.

attribute sqlalchemy.orm.Bundle.is_bundle = True

True if this object is an instance of Bundle.

attribute sqlalchemy.orm.Bundle.is_clause_element = False

True if this object is an instance of ClauseElement.

attribute sqlalchemy.orm.Bundle.is_mapper = False

True if this object is an instance of Mapper.

method sqlalchemy.orm.Bundle.label(name)

Provide a copy of this Bundle passing a new label.

attribute sqlalchemy.orm.Bundle.single_entity = False

If True, queries for a single Bundle will be returned as a single entity, rather than an element within a keyed tuple.

class sqlalchemy.orm.Load(entity)

Represents loader options which modify the state of a Query in order to affect how various mapped attributes are loaded.

The Load object is in most cases used implicitly behind the scenes when one makes use of a query option like joinedload(), defer(), or similar. However, the Load object can also be used directly, and in some cases can be useful.

To use Load directly, instantiate it with the target mapped class as the argument. This style of usage is useful when dealing with a Query that has multiple entities:

myopt = Load(MyClass).joinedload("widgets")

The above myopt can now be used with Query.options(), where it will only take effect for the MyClass entity:

session.query(MyClass, MyOtherClass).options(myopt)

One case where Load is useful as public API is when specifying “wildcard” options that only take effect for a certain class:

session.query(Order).options(Load(Order).lazyload('*'))

Above, all relationships on Order will be lazy-loaded, but other attributes on those descendant objects will load using their normal loader strategy.

Class signature

class sqlalchemy.orm.Load (sqlalchemy.sql.expression.Generative, sqlalchemy.orm.LoaderOption)

method sqlalchemy.orm.Load.baked_lazyload(attr)

Produce a new Load object with the baked_lazyload() option applied.

See baked_lazyload() for usage examples.

method sqlalchemy.orm.Load.contains_eager(attr, alias=None)

Produce a new Load object with the contains_eager() option applied.

See contains_eager() for usage examples.

method sqlalchemy.orm.Load.defaultload(attr)

Produce a new Load object with the defaultload() option applied.

See defaultload() for usage examples.

method sqlalchemy.orm.Load.defer(key, raiseload=False)

Produce a new Load object with the defer() option applied.

See defer() for usage examples.

method sqlalchemy.orm.Load.immediateload(attr)

Produce a new Load object with the immediateload() option applied.

See immediateload() for usage examples.

method sqlalchemy.orm.Load.joinedload(attr, innerjoin=None)

Produce a new Load object with the joinedload() option applied.

See joinedload() for usage examples.

method sqlalchemy.orm.Load.lazyload(attr)

Produce a new Load object with the lazyload() option applied.

See lazyload() for usage examples.

method sqlalchemy.orm.Load.load_only(*attrs)

Produce a new Load object with the load_only() option applied.

See load_only() for usage examples.

method sqlalchemy.orm.Load.noload(attr)

Produce a new Load object with the noload() option applied.

See noload() for usage examples.

method sqlalchemy.orm.Load.options(*opts)

Apply a series of options as sub-options to this Load object.

E.g.:

query = session.query(Author)
query = query.options(
            joinedload(Author.book).options(
                load_only(Book.summary, Book.excerpt),
                joinedload(Book.citations).options(
                    joinedload(Citation.author)
                )
            )
        )
Parameters:

*opts – A series of loader option objects (ultimately Load objects) which should be applied to the path specified by this Load object.

New in version 1.3.6.

method sqlalchemy.orm.Load.process_compile_state(compile_state)

Apply a modification to a given CompileState.

method sqlalchemy.orm.Load.process_compile_state_replaced_entities(compile_state, mapper_entities)

Apply a modification to a given CompileState, given entities that were replaced by with_only_columns() or with_entities().

New in version 1.4.19.

attribute sqlalchemy.orm.Load.propagate_to_loaders = False

if True, indicate this option should be carried along to “secondary” SELECT statements that occur for relationship lazy loaders as well as attribute load / refresh operations.

method sqlalchemy.orm.Load.raiseload(attr, sql_only=False)

Produce a new Load object with the raiseload() option applied.

See raiseload() for usage examples.

method sqlalchemy.orm.Load.selectin_polymorphic(classes)

Produce a new Load object with the selectin_polymorphic() option applied.

See selectin_polymorphic() for usage examples.

method sqlalchemy.orm.Load.selectinload(attr)

Produce a new Load object with the selectinload() option applied.

See selectinload() for usage examples.

method sqlalchemy.orm.Load.subqueryload(attr)

Produce a new Load object with the subqueryload() option applied.

See subqueryload() for usage examples.

method sqlalchemy.orm.Load.undefer(key)

Produce a new Load object with the undefer() option applied.

See undefer() for usage examples.

method sqlalchemy.orm.Load.undefer_group(name)

Produce a new Load object with the undefer_group() option applied.

See undefer_group() for usage examples.

method sqlalchemy.orm.Load.with_expression(key, expression)

Produce a new Load object with the with_expression() option applied.

See with_expression() for usage examples.

function sqlalchemy.orm.with_loader_criteria(entity_or_base, where_criteria, loader_only=False, include_aliases=False, propagate_to_loaders=True, track_closure_variables=True)

Add additional WHERE criteria to the load for all occurrences of a particular entity.

New in version 1.4.

The with_loader_criteria() option is intended to add limiting criteria to a particular kind of entity in a query, globally, meaning it will apply to the entity as it appears in the SELECT query as well as within any subqueries, join conditions, and relationship loads, including both eager and lazy loaders, without the need for it to be specified in any particular part of the query. The rendering logic uses the same system used by single table inheritance to ensure a certain discriminator is applied to a table.

E.g., using 2.0-style queries, we can limit the way the User.addresses collection is loaded, regardless of the kind of loading used:

from sqlalchemy.orm import with_loader_criteria

stmt = select(User).options(
    selectinload(User.addresses),
    with_loader_criteria(Address, Address.email_address != 'foo'))
)

Above, the “selectinload” for User.addresses will apply the given filtering criteria to the WHERE clause.

Another example, where the filtering will be applied to the ON clause of the join, in this example using 1.x style queries:

q = session.query(User).outerjoin(User.addresses).options(
    with_loader_criteria(Address, Address.email_address != 'foo'))
)

The primary purpose of with_loader_criteria() is to use it in the SessionEvents.do_orm_execute() event handler to ensure that all occurrences of a particular entity are filtered in a certain way, such as filtering for access control roles. It also can be used to apply criteria to relationship loads. In the example below, we can apply a certain set of rules to all queries emitted by a particular Session:

session = Session(bind=engine)

@event.listens_for("do_orm_execute", session)
def _add_filtering_criteria(execute_state):

    if (
        execute_state.is_select
        and not execute_state.is_column_load
        and not execute_state.is_relationship_load
    ):
        execute_state.statement = execute_state.statement.options(
            with_loader_criteria(
                SecurityRole,
                lambda cls: cls.role.in_(['some_role']),
                include_aliases=True
            )
        )

In the above example, the SessionEvents.do_orm_execute() event will intercept all queries emitted using the Session. For those queries which are SELECT statements and are not attribute or relationship loads a custom with_loader_criteria() option is added to the query. The with_loader_criteria() option will be used in the given statement and will also be automatically propagated to all relationship loads that descend from this query.

The criteria argument given is a lambda that accepts a cls argument. The given class will expand to include all mapped subclass and need not itself be a mapped class.

Tip

When using with_loader_criteria() option in conjunction with the contains_eager() loader option, it’s important to note that with_loader_criteria() only affects the part of the query that determines what SQL is rendered in terms of the WHERE and FROM clauses. The contains_eager() option does not affect the rendering of the SELECT statement outside of the columns clause, so does not have any interaction with the with_loader_criteria() option. However, the way things “work” is that contains_eager() is meant to be used with a query that is already selecting from the additional entities in some way, where with_loader_criteria() can apply it’s additional criteria.

In the example below, assuming a mapping relationship as A -> A.bs -> B, the given with_loader_criteria() option will affect the way in which the JOIN is rendered:

stmt = select(A).join(A.bs).options(
    contains_eager(A.bs),
    with_loader_criteria(B, B.flag == 1)
)

Above, the given with_loader_criteria() option will affect the ON clause of the JOIN that is specified by .join(A.bs), so is applied as expected. The contains_eager() option has the effect that columns from B are added to the columns clause:

SELECT
    b.id, b.a_id, b.data, b.flag,
    a.id AS id_1,
    a.data AS data_1
FROM a JOIN b ON a.id = b.a_id AND b.flag = :flag_1

The use of the contains_eager() option within the above statement has no effect on the behavior of the with_loader_criteria() option. If the contains_eager() option were omitted, the SQL would be the same as regards the FROM and WHERE clauses, where with_loader_criteria() continues to add its criteria to the ON clause of the JOIN. The addition of contains_eager() only affects the columns clause, in that additional columns against b are added which are then consumed by the ORM to produce B instances.

Warning

The use of a lambda inside of the call to with_loader_criteria() is only invoked once per unique class. Custom functions should not be invoked within this lambda. See Using Lambdas to add significant speed gains to statement production for an overview of the “lambda SQL” feature, which is for advanced use only.

Parameters:
  • entity_or_base – a mapped class, or a class that is a super class of a particular set of mapped classes, to which the rule will apply.

  • where_criteria

    a Core SQL expression that applies limiting criteria. This may also be a “lambda:” or Python function that accepts a target class as an argument, when the given class is a base with many different mapped subclasses.

    Note

    To support pickling, use a module-level Python function to produce the SQL expression instead of a lambda or a fixed SQL expression, which tend to not be picklable.

  • include_aliases – if True, apply the rule to aliased() constructs as well.

  • propagate_to_loaders – defaults to True, apply to relationship loaders such as lazy loaders. This indicates that the option object itself including SQL expression is carried along with each loaded instance. Set to False to prevent the object from being assigned to individual instances.

See also

ORM Query Events - includes examples of using with_loader_criteria().

Adding global WHERE / ON criteria - basic example on how to combine with_loader_criteria() with the SessionEvents.do_orm_execute() event.

Parameters:

track_closure_variables

when False, closure variables inside of a lambda expression will not be used as part of any cache key. This allows more complex expressions to be used inside of a lambda expression but requires that the lambda ensures it returns the identical SQL every time given a particular class.

New in version 1.4.0b2.

function sqlalchemy.orm.join(left, right, onclause=None, isouter=False, full=False, join_to_left=None)

Produce an inner join between left and right clauses.

join() is an extension to the core join interface provided by join(), where the left and right selectables may be not only core selectable objects such as Table, but also mapped classes or AliasedClass instances. The “on” clause can be a SQL expression or an ORM mapped attribute referencing a configured relationship().

Deprecated since version 1.4: using a string relationship name for the “onclause” is deprecated and will be removed in 2.0; the onclause may be only an ORM-mapped relationship attribute or a SQL expression construct.

join() is not commonly needed in modern usage, as its functionality is encapsulated within that of the Select.join() and Query.join() methods. which feature a significant amount of automation beyond join() by itself. Explicit use of join() with ORM-enabled SELECT statements involves use of the Select.select_from() method, as in:

from sqlalchemy.orm import join
stmt = select(User).\
    select_from(join(User, Address, User.addresses)).\
    filter(Address.email_address=='foo@bar.com')

In modern SQLAlchemy the above join can be written more succinctly as:

stmt = select(User).\
        join(User.addresses).\
        filter(Address.email_address=='foo@bar.com')

Warning

using join() directly may not work properly with modern ORM options such as with_loader_criteria(). It is strongly recommended to use the idiomatic join patterns provided by methods such as Select.join() and Select.join_from() when creating ORM joins.

See also

Joins - in the ORM Querying Guide for background on idiomatic ORM join patterns

function sqlalchemy.orm.outerjoin(left, right, onclause=None, full=False, join_to_left=None)

Produce a left outer join between left and right clauses.

This is the “outer join” version of the join() function, featuring the same behavior except that an OUTER JOIN is generated. See that function’s documentation for other usage details.

function sqlalchemy.orm.with_parent(instance, prop, from_entity=None)

Create filtering criterion that relates this query’s primary entity to the given related instance, using established relationship() configuration.

E.g.:

stmt = select(Address).where(with_parent(some_user, User.addresses))

The SQL rendered is the same as that rendered when a lazy loader would fire off from the given parent on that attribute, meaning that the appropriate state is taken from the parent object in Python without the need to render joins to the parent table in the rendered statement.

The given property may also make use of PropComparator.of_type() to indicate the left side of the criteria:

a1 = aliased(Address)
a2 = aliased(Address)
stmt = select(a1, a2).where(
    with_parent(u1, User.addresses.of_type(a2))
)

The above use is equivalent to using the from_entity() argument:

a1 = aliased(Address)
a2 = aliased(Address)
stmt = select(a1, a2).where(
    with_parent(u1, User.addresses, from_entity=a2)
)
Parameters:
  • instance – An instance which has some relationship().

  • property

    String property name, or class-bound attribute, which indicates what relationship from the instance should be used to reconcile the parent/child relationship.

    Deprecated since version 1.4: Using strings is deprecated and will be removed in SQLAlchemy 2.0. Please use the class-bound attribute directly.

  • from_entity

    Entity in which to consider as the left side. This defaults to the “zero” entity of the Query itself.

    New in version 1.2.