SQLAlchemy 0.7 Documentation

Release: 0.7.10 | Release Date: February 7, 2013 | Download PDF

Querying

This section provides API documentation for the Query object and related constructs.

For an in-depth introduction to querying with the SQLAlchemy ORM, please see the Object Relational Tutorial.

The Query Object

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

q = session.query(SomeMappedClass)

Following is the full interface for the Query object.

class sqlalchemy.orm.query.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 query() method of Session. For a full walkthrough of Query usage, see the Object Relational Tutorial.

add_column(column)

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

Pending deprecation: add_column() will be superseded by add_columns().

add_columns(*column)

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

add_entity(entity, alias=None)

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

all()

Return the results represented by this Query as a list.

This results in an execution of the underlying query.

as_scalar()

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

Analogous to sqlalchemy.sql._SelectBaseMixin.as_scalar().

New in version 0.6.5.

autoflush(setting)

Return a Query with a specific ‘autoflush’ setting.

Note that a Session with autoflush=False will not autoflush, even if this flag is set to True at the Query level. Therefore this flag is usually used only to disable autoflush for a specific 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,
    },
    {
        'name':'id',
        'type':Integer(),
        'aliased':False,
        'expr':User.id,
    },
    {
        'name':'user2',
        'type':User,
        'aliased':True,
        'expr':user_alias
    }
]
correlate(*args)

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.

count()

Return a count of rows 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

Changed in version 0.7: The above scheme is newly refined as of 0.7b3.

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 func expressions in conjunction with 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)))
cte(name=None, recursive=False)

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

New in version 0.7.6.

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 orm.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.part,
        parts_alias.sub_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:

_SelectBase.cte()

delete(synchronize_session='evaluate')

Perform a bulk delete query.

Deletes rows matched by this query from the database.

Parameters:synchronize_session

chooses the strategy for the removal of matched objects from the session. Valid values are:

False - don’t synchronize the session. This option is the most efficient and is reliable once the session is expired, which typically occurs after a commit(), or explicitly using expire_all(). Before the expiration, objects may still remain in the session which were in fact deleted which can lead to confusing results if they are accessed via get() or already loaded collections.

'fetch' - performs a select query before the delete to find objects that are matched by the delete query and need to be removed from the session. Matched objects are removed from the session.

'evaluate' - Evaluate the query’s criteria in Python straight on the objects in the session. If evaluation of the criteria isn’t implemented, an error is raised. In that case you probably want to use the ‘fetch’ strategy as a fallback.

The expression evaluator currently doesn’t account for differing string collations between the database and Python.

Returns the number of rows deleted, excluding any cascades.

The method does not offer in-Python cascading of relationships - it is assumed that ON DELETE CASCADE is configured for any foreign key references which require it. The Session needs to be expired (occurs automatically after commit(), or call expire_all()) in order for the state of dependent objects subject to delete or delete-orphan cascade to be correctly represented.

Note that the MapperEvents.before_delete() and MapperEvents.after_delete() events are not invoked from this method. It instead invokes SessionEvents.after_bulk_delete().

distinct(*criterion)

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

Parameters:*expr – optional column expressions. When present, the Postgresql dialect will render a DISTINCT ON (<expressions>>) construct.
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.

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.

except_(*q)

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

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

except_all(*q)

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

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

execution_options(**kwargs)

Set non-SQL options which take effect during execution.

The options are the same as those accepted by Connection.execution_options().

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

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 are joined together by AND:

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.

Changed in version 0.7.5: Multiple criteria joined by AND.

See also:

Query.filter_by() - filter on keyword expressions.

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 are joined together by AND:

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.

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 first() results in an execution of the underlying query.

from_self(*entities)

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

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

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 argument is either a string, a select() construct, or a text() construct, and should return the set of columns appropriate to the entity class represented by this Query.

get(ident)

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

E.g.:

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

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

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.

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.

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 options() may be applied however, and will be used if the object is not yet locally present.

A lazy-loading, many-to-one attribute configured by relationship(), using a simple foreign-key-to-primary-key criterion, will also use an operation equivalent to get() in order to retrieve the target value from the local identity map before querying the database. See Relationship Loading Techniques for further details on relationship loading.

Parameters:ident – A scalar or tuple value representing the primary key. For a composite primary key, the order of identifiers corresponds in most cases to that of the mapped Table object’s primary key columns. For a mapper() that was given the primary key argument during construction, the order of identifiers corresponds to the elements present in this collection.
Returns:The object instance, or None.
group_by(*criterion)

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

having(criterion)

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

having() is used in conjunction with 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)
instances(cursor, _Query__context=None)

Given a ResultProxy cursor as returned by connection.execute(), return an ORM result as an iterator.

e.g.:

result = engine.execute("select * from users")
for u in session.query(User).instances(result):
    print u
intersect(*q)

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

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

intersect_all(*q)

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

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

join(*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 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 join() along User.addresses will result in SQL equivalent to:

SELECT user.* FROM user JOIN address ON user.id = address.user_id

In the above example we refer to User.addresses as passed to join() as the on clause, that is, it indicates how the “ON” portion of the JOIN should be constructed. For a single-entity query such as the one above (i.e. we start by selecting only from User and nothing else), the relationship can also be specified by its string name:

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

join() can also accommodate multiple “on clause” arguments to produce a chain of joins, such as below where a join across four related entities is constructed:

q = session.query(User).join("orders", "items", "keywords")

The above would be shorthand for three separate calls to join(), each using an explicit attribute to indicate the source entity:

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

Joins to a Target Entity or Selectable

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

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

The above calling form of join() will raise an error if either there are no foreign keys between the two entities, or if there are multiple foreign key linkages between them. In the above calling form, join() is called upon to create the “on clause” automatically for us. The target can be any mapped entity or selectable, such as a Table:

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

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. Suppose for example we wanted to join to Address twice, using an alias the second time. We use aliased() to create a distinct alias of Address, and join to it using the target, onclause form, so that the alias can be specified explicitly as the target along with the relationship to instruct how the ON clause should proceed:

a_alias = aliased(Address)

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

Where above, the generated SQL would be similar to:

SELECT user.* FROM user
    JOIN address ON user.id = address.user_id
    JOIN address AS address_1 ON user.id=address_1.user_id
    WHERE address.email_address = :email_address_1
    AND address_1.email_address = :email_address_2

The two-argument calling form of join() also allows us to construct arbitrary joins with SQL-oriented “on clause” expressions, not relying upon configured relationships at all. Any SQL expression can be passed as the ON clause when using the two-argument form, which should refer to the target entity in some way as well as an applicable source entity:

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

Changed in version 0.7: In SQLAlchemy 0.6 and earlier, the two argument form of join() requires the usage of a tuple: query(User).join((Address, User.id==Address.user_id)). This calling form is accepted in 0.7 and further, though is not necessary unless multiple join conditions are passed to a single join() call, which itself is also not generally necessary as it is now equivalent to multiple calls (this wasn’t always the case).

Advanced Join Targeting and Adaption

There is a lot of flexibility in what the “target” can be when using join(). As noted previously, it also accepts Table constructs and other selectables such as alias() and select() constructs, with either the one or two-argument forms:

addresses_q = select([Address.user_id]).\
                where(Address.email_address.endswith("@bar.com")).\
                alias()

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

join() also features the ability to adapt a relationship() -driven ON clause to the target selectable. Below we construct a JOIN from User to a subquery against Address, allowing the relationship denoted by User.addresses to adapt itself to the altered target:

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

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

Producing SQL similar to:

SELECT user.* FROM user
    JOIN (
        SELECT address.id AS id,
                address.user_id AS user_id,
                address.email_address AS email_address
        FROM address
        WHERE address.email_address = :email_address_1
    ) AS anon_1 ON user.id = anon_1.user_id

The above form allows one to fall back onto an explicit ON clause at any time:

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

Controlling what to Join From

While join() exclusively deals with the “right” side of the JOIN, we can also control the “left” side, in those cases where it’s needed, using select_from(). Below we construct a query against Address but can still make usage of User.addresses as our ON clause by instructing the Query to select first from the User entity:

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

Constructing Aliases Anonymously

join() can construct anonymous aliases using the aliased=True flag. This feature is useful when a query is being joined algorithmically, such as when querying self-referentially to an arbitrary depth:

q = session.query(Node).\
        join("children", "children", aliased=True)

When aliased=True is used, the actual “alias” construct is not explicitly available. To work with it, methods such as Query.filter() will adapt the incoming entity to the last join point:

q = session.query(Node).\
        join("children", "children", aliased=True).\
        filter(Node.name == 'grandchild 1')

When using automatic aliasing, the from_joinpoint=True argument can allow a multi-node join to be broken into multiple calls to join(), so that each path along the way can be further filtered:

q = session.query(Node).\
        join("children", aliased=True).\
        filter(Node.name='child 1').\
        join("children", aliased=True, from_joinpoint=True).\
        filter(Node.name == 'grandchild 1')

The filtering aliases above can then be reset back to the original Node entity using reset_joinpoint():

q = session.query(Node).\
        join("children", "children", aliased=True).\
        filter(Node.name == 'grandchild 1').\
        reset_joinpoint().\
        filter(Node.name == 'parent 1)

For an example of aliased=True, see the distribution example XML Persistence which illustrates an XPath-like query system using algorithmic joins.

Parameters:
  • *props

    A collection of one or more join conditions, each consisting of a relationship-bound attribute or string relationship name representing an “on clause”, or a single target entity, or a tuple in the form of (target, onclause). A special two-argument calling form of the form target, onclause is also accepted.

  • aliased=False – If True, indicate that the JOIN target should be anonymously aliased. Subsequent calls to filter and similar will adapt the incoming criterion to the target alias, until reset_joinpoint() is called.
  • 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.

See also:

Querying with Joins in the ORM tutorial.

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

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

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 sqlalchemy.sql._SelectBaseMixin.label().

New in version 0.6.5.

limit(limit)

Apply a LIMIT to the query and return the newly resulting

Query.

logger = <logging.Logger object at 0x5735750>
merge_result(iterator, load=True)

Merge a result into this Query object’s Session.

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 merge_result() is used, see the source code for the example Beaker Caching, where merge_result() is used to efficiently restore state from a cache back into a target Session.

offset(offset)

Apply an OFFSET to the query and return the newly resulting 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 does not return object identities.

Note that an entity query, that is, one which selects one or more mapped classes as opposed to individual column attributes, may ultimately represent many rows but only one row of unique entity or entities - this is a successful result for one().

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

Changed in version 0.6: one() fully fetches all results instead of applying any kind of limit, so that the “unique”-ing of entities does not conceal multiple object identities.

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. See the sections Deferred Column Loading and Relationship Loading Techniques for reference documentation.

order_by(*criterion)

apply one or more ORDER BY criterion to the query and return the newly resulting Query

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

Alternatively, an existing ORDER BY setting on the Query object can be entirely cancelled by passing False as the value - use this before calling methods where an ORDER BY is invalid.

outerjoin(*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.

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.

populate_existing()

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

populate_existing() does not improve behavior when the ORM is used normally - the Session object’s usual behavior of maintaining a transaction and expiring all attributes after rollback or commit handles object state automatically. This method is not intended for general use.

prefix_with(*prefixes)

Apply the prefixes to the query and return the newly resulting Query.

Parameters:*prefixes – optional prefixes, typically strings,

not using any commas. In particular is useful for MySQL keywords.

e.g.:

query = sess.query(User.name).\
    prefix_with('HIGH_PRIORITY').\
    prefix_with('SQL_SMALL_RESULT', 'ALL')

Would render:

SELECT HIGH_PRIORITY SQL_SMALL_RESULT ALL users.name AS users_name
FROM users

New in version 0.7.7.

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 join() method. See the example in join() for how this is used.

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.

select_from(*from_obj)

Set the FROM clause of this Query explicitly.

Sending a mapped class or entity here effectively replaces the “left edge” of any calls to 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.

Mapped entities or plain Table or other selectables can be sent here which will form the default FROM clause.

See the example in join() for a typical usage of select_from().

slice(start, stop)

apply LIMIT/OFFSET to the Query based on a ” “range and return the newly resulting 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.

subquery(name=None)

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

Eager JOIN generation within the query is disabled.

The statement will not have disambiguating labels applied to the list of selected columns unless the Query.with_labels() method is used to generate a new Query with the option enabled.

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.
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.

union_all(*q)

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

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

update(values, synchronize_session='evaluate')

Perform a bulk update query.

Updates rows matched by this query in the database.

Parameters:
  • values – a dictionary with attributes names as keys and literal values or sql expressions as values.
  • synchronize_session

    chooses the strategy to update the attributes on objects in the session. Valid values are:

    False - don’t synchronize the session. This option is the most efficient and is reliable once the session is expired, which typically occurs after a commit(), or explicitly using expire_all(). Before the expiration, updated objects may still remain in the session with stale values on their attributes, which can lead to confusing results.

    'fetch' - performs a select query before the update to find objects that are matched by the update query. The updated attributes are expired on matched objects.

    'evaluate' - Evaluate the Query’s criteria in Python straight on the objects in the session. If evaluation of the criteria isn’t implemented, an exception is raised.

    The expression evaluator currently doesn’t account for differing string collations between the database and Python.

Returns the number of rows matched by the update.

The method does not offer in-Python cascading of relationships - it is assumed that ON UPDATE CASCADE is configured for any foreign key references which require it.

The Session needs to be expired (occurs automatically after commit(), or call expire_all()) in order for the state of dependent objects subject foreign key cascade to be correctly represented.

Note that the MapperEvents.before_update() and MapperEvents.after_update() events are not invoked from this method. It instead invokes SessionEvents.after_bulk_update().

value(column)

Return a scalar result corresponding to the given column expression.

values(*columns)

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

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.

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)

New in version 0.6.5.

with_hint(selectable, text, dialect_name='*')

Add an indexing hint for the given entity or selectable to this Query.

Functionality is passed straight through to with_hint(), with the addition that selectable can be a Table, Alias, or ORM entity / mapped class /etc.

with_labels()

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.

with_lockmode(mode)

Return a new Query object with the specified locking mode.

Parameters:mode

a string representing the desired locking mode. A corresponding value is passed to the for_update parameter of select() when the query is executed. Valid values are:

'update' - passes for_update=True, which translates to FOR UPDATE (standard SQL, supported by most dialects)

'update_nowait' - passes for_update='nowait', which translates to FOR UPDATE NOWAIT (supported by Oracle, PostgreSQL 8.1 upwards)

'read' - passes for_update='read', which translates to LOCK IN SHARE MODE (for MySQL), and FOR SHARE (for PostgreSQL)

'read_nowait' - passes for_update='read_nowait', which translates to FOR SHARE NOWAIT (supported by PostgreSQL).

New in version 0.7.7: FOR SHARE and FOR SHARE NOWAIT (PostgreSQL).

with_parent(instance, property=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.

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.

with_polymorphic(cls_or_mappers, selectable=None, discriminator=None)

Load columns for descendant mappers of this Query’s mapper.

Using this method will ensure that each descendant mapper’s tables are included in the FROM clause, and will allow filter() criterion to be used against those tables. The resulting instances will also have those columns already loaded so that no “post fetch” of those columns will be required.

Parameters:
  • cls_or_mappers – a single class or mapper, or list of class/mappers, which inherit from this Query’s mapper. Alternatively, it may also be the string '*', in which case all descending mappers will be added to the FROM clause.
  • selectable – a table or select() statement that will be used in place of the generated FROM clause. This argument is required if any of the desired mappers use concrete table inheritance, since SQLAlchemy currently cannot generate UNIONs among tables automatically. If used, the selectable argument must represent the full set of tables and columns mapped by every desired mapper. Otherwise, the unaccounted mapped columns will result in their table being appended directly to the FROM clause which will usually lead to incorrect results.
  • discriminator – a column to be used as the “discriminator” column for the given selectable. If not given, the polymorphic_on attribute of the mapper will be used, if any. This is useful for mappers that don’t have polymorphic loading behavior by default, such as concrete table mappers.
with_session(session)

Return a Query that will use the given Session.

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.

New in version 0.7.4.

yield_per(count)

Yield only count rows at a time.

WARNING: use this method with caution; if the same instance is present in more than one batch of rows, end-user changes to attributes will be overwritten.

In particular, it’s usually impossible to use this setting with eagerly loaded collections (i.e. any lazy=’joined’ or ‘subquery’) since those collections will be cleared for a new load when encountered in a subsequent result batch. In the case of ‘subquery’ loading, the full result for all rows is fetched which generally defeats the purpose of yield_per().

Also note that while yield_per() will set the stream_results execution option to True, currently this is only understood by psycopg2 dialect which will stream results using server side cursors instead of pre-buffer all rows for this query. Other DBAPIs pre-buffer all rows before making them available.

ORM-Specific Query Constructs

class sqlalchemy.orm.aliased

The public name of the AliasedClass class.

class sqlalchemy.orm.util.AliasedClass(cls, alias=None, name=None, adapt_on_names=False)

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

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

Usage is via the aliased() synonym:

# 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)

The resulting object is an instance of AliasedClass, however it implements a __getattribute__() scheme which will proxy attribute access to that of the ORM class being aliased. All classmethods on the mapped entity should also be available here, including hybrids created with the Hybrid Attributes extension, which will receive the AliasedClass as the “class” argument when classmethods are called.

Parameters:
  • cls – ORM mapped entity which will be “wrapped” around an alias.
  • alias – a selectable, such as an alias() or select() construct, which will be rendered in place of the mapped table of the ORM entity. If left as None, an ordinary Alias of the ORM entity’s mapped table will be generated.
  • name – A name which will be applied both to the Alias if one is generated, as well as the name present in the “named tuple” returned by the Query object when results are returned.
  • 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 fund.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.

    New in version 0.7.3.

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

Produce an inner join between left and right clauses.

orm.join() is an extension to the core join interface provided by sql.expression.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 attribute or string name referencing a configured relationship().

join_to_left indicates to attempt aliasing the ON clause, in whatever form it is passed, to the selectable passed as the left side. If False, the onclause is used as is.

orm.join() is not commonly needed in modern usage, as its functionality is encapsulated within that of the Query.join() method, which features a significant amount of automation beyond orm.join() by itself. Explicit usage of orm.join() with Query involves usage of the Query.select_from() method, as in:

from sqlalchemy.orm import join
session.query(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:

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

See Query.join() for information on modern usage of ORM level joins.

sqlalchemy.orm.outerjoin(left, right, onclause=None, join_to_left=True)

Produce a left outer join between left and right clauses.

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

sqlalchemy.orm.with_parent(instance, prop)

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

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.

Changed in version 0.6.4: This method accepts parent instances in all persistence states, including transient, persistent, and detached. Only the requisite primary key/foreign key attributes need to be populated. Previous versions didn’t work with transient instances.

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.