Relationship Loading Techniques
===============================
-A big part of SQLAlchemy is providing a wide range of control over how related objects get loaded when querying. This behavior
-can be configured at mapper construction time using the ``lazy`` parameter to the :func:`.relationship` function,
-as well as by using options with the :class:`.Query` object.
+A big part of SQLAlchemy is providing a wide range of control over how related
+objects get loaded when querying. By "related objects" we refer to collections
+or scalar associations configured on a mapper using :func:`.relationship`.
+This behavior can be configured at mapper construction time using the
+:paramref:`.relationship.lazy` parameter to the :func:`.relationship`
+function, as well as by using options with the :class:`.Query` object.
+
+The loading of relationships falls into three categories; **lazy** loading,
+**eager** loading, and **no** loading. Lazy loading refers to objects are returned
+from a query without the related
+objects loaded at first. When the given collection or reference is
+first accessed on a particular object, an additional SELECT statement
+is emitted such that the requested collection is loaded.
+
+Eager loading refers to objects returned from a query with the related
+collection or scalar reference already loaded up front. The :class:`.Query`
+achieves this either by augmenting the SELECT statement it would normally
+emit with a JOIN to load in related rows simultaneously, or by emitting
+additional SELECT statements after the primary one to load collections
+or scalar references at once.
+
+"No" loading refers to the disabling of loading on a given relationship, either
+that the attribute is empty and is just never loaded, or that it raises
+an error when it is accessed, in order to guard against unwanted lazy loads.
+
+The primary forms of relationship loading are:
+
+* **lazy loading** - available via ``lazy='select'`` or the :func:`.lazyload`
+ option, this is the form of loading that emits a SELECT statement at
+ attribute access time to lazily load a related reference on a single
+ object at a time. Lazy loading is detailed at :ref:`lazy_loading`.
+
+* **joined loading** - available via ``lazy='joined'`` or the :func:`.joinedload`
+ option, this form of loading applies a JOIN to the given SELECT statement
+ so that related rows are loaded in the same result set. Joined eager loading
+ is detailed at :ref:`joined_eager_loading`.
+
+* **subquery loading** - available via ``lazy='subquery'`` or the :func:`.subqueryload`
+ option, this form of loading emits a second SELECT statement which re-states the
+ original query embedded inside of a subquery, then JOINs that subquery to the
+ related table to be loaded to load all members of related collections / scalar
+ references at once. Subquery eager loading is detailed at :ref:`subquery_eager_loading`.
+
+* **raise loading** - available via ``lazy='raise'``, ``lazy='raise_sql'``,
+ or the :func:`.raiseload` option, this form of loading is triggered at the
+ same time a lazy load would normally occur, except it raises an ORM exception
+ in order to guard against the application making unwanted lazy loads.
+ An introduction to raise loading is at :ref:`prevent_lazy_with_raiseload`.
+
+* **no loading** - available via ``lazy='noload'``, or the :func:`.noload`
+ option; this loading style turns the attribute into an empty attribute that
+ will never load or have any loading effect. "noload" is a fairly
+ uncommon loader option.
+
+
+
+Configuring Loader Strategies at Mapping Time
+---------------------------------------------
+
+The loader strategy for a particular relationship can be configured
+at mapping time to take place in all cases where an object of the mapped
+type is loaded, in the absense of any query-level options that modify it.
+This is configured using the :paramref:`.relationship.lazy` parameter to
+:func:`.relationship`; common values for this parameter
+include ``select``, ``joined``, and ``subquery``.
+
+For example, to configure a relationship to use joined eager loading when
+the parent object is queried::
-Using Loader Strategies: Lazy Loading, Eager Loading
-----------------------------------------------------
+ # load the 'children' collection using LEFT OUTER JOIN
+ class Parent(Base):
+ __tablename__ = 'parent'
+
+ id = Column(Integer, primary_key=True)
+ children = relationship("Child", lazy='joined')
+
+Above, whenever a collection of ``Parent`` objects are loaded, each
+``Parent`` will also have its ``children`` collection populated, using
+rows fetched by adding a JOIN to the query for ``Parent`` objects.
+See :ref:`joined_eager_loading` for background on this style of loading.
+
+The default value of the :paramref:`.relationship.lazy` argument is
+``select``, which indicates lazy loading. See :ref:`lazy_loading` for
+further background.
+
+.. _relationship_loader_options:
+
+Controlling Loading via Options
+-------------------------------
+
+The other, and possibly more common way to configure loading strategies
+is to set them up on a per-query basis against specific attributes. Very detailed
+control over relationship loading is available using loader options;
+the most common are
+:func:`~sqlalchemy.orm.joinedload`,
+:func:`~sqlalchemy.orm.subqueryload`,
+and :func:`~sqlalchemy.orm.lazyload`. The option accepts either
+the string name of an attribute against a parent, or for greater specificity
+can accommodate a class-bound attribute directly::
+
+ # set children to load lazily
+ session.query(Parent).options(lazyload('children')).all()
+
+ # same, using class-bound attribute
+ session.query(Parent).options(lazyload(Parent.children)).all()
+
+ # set children to load eagerly with a join
+ session.query(Parent).options(joinedload('children')).all()
+
+The loader options can also be "chained" using **method chaining**
+to specify how loading should occur further levels deep::
+
+ session.query(Parent).options(
+ joinedload(Parent.children).
+ subqueryload(Child.subelements)).all()
+
+Chained loader options can be applied against a "lazy" loaded collection.
+This means that when a collection or association is lazily loaded upon
+access, the specified option will then take effect::
+
+ session.query(Parent).options(
+ lazyload(Parent.children).
+ subqueryload(Child.subelements)).all()
+
+Above, the query will return ``Parent`` objects without the ``children``
+collections loaded. When the ``children`` collection on a particular
+``Parent`` object is first accessed, it will lazy load the related
+objects, but additionally apply eager loading to the ``subelements``
+collection on each member of ``children``.
+
+Using method chaining, the loader style of each link in the path is explicitly
+stated. To navigate along a path without changing the existing loader style
+of a particular attribute, the :func:`.defaultload` method/function may be used::
+
+ session.query(A).options(
+ defaultload("atob").
+ joinedload("btoc")).all()
+
+.. _lazy_loading:
+
+Lazy Loading
+------------
By default, all inter-object relationships are **lazy loading**. The scalar or
collection attribute associated with a :func:`~sqlalchemy.orm.relationship`
contains a trigger which fires the first time the attribute is accessed. This
-trigger, in all but one case, issues a SQL call at the point of access
+trigger typically issues a SQL call at the point of access
in order to load the related object or objects:
.. sourcecode:: python+sql
- {sql}>>> jack.addresses
- SELECT addresses.id AS addresses_id, addresses.email_address AS addresses_email_address,
- addresses.user_id AS addresses_user_id
+ >>> jack.addresses
+ {opensql}SELECT
+ addresses.id AS addresses_id,
+ addresses.email_address AS addresses_email_address,
+ addresses.user_id AS addresses_user_id
FROM addresses
WHERE ? = addresses.user_id
[5]
The one case where SQL is not emitted is for a simple many-to-one relationship, when
the related object can be identified by its primary key alone and that object is already
-present in the current :class:`.Session`.
+present in the current :class:`.Session`. For this reason, while lazy loading
+can be expensive for related collections, in the case that one is loading
+lots of objects with simple many-to-ones against a relatively small set of
+possible target objects, lazy loading may be able to refer to these objects locally
+without emitting as many SELECT statements as there are parent objects.
This default behavior of "load upon attribute access" is known as "lazy" or
"select" loading - the name "select" because a "SELECT" statement is typically emitted
when the attribute is first accessed.
-In the :ref:`ormtutorial_toplevel`, we introduced the concept of **Eager
-Loading**. We used an ``option`` in conjunction with the
-:class:`~sqlalchemy.orm.query.Query` object in order to indicate that a
-relationship should be loaded at the same time as the parent, within a single
-SQL query. This option, known as :func:`.joinedload`, connects a JOIN (by default
-a LEFT OUTER join) to the statement and populates the scalar/collection from the
-same result set as that of the parent:
-
-.. sourcecode:: python+sql
+Lazy loading can be enabled for a given attribute that is normally
+configured in some other way using the :func:`.lazyload` loader option::
- {sql}>>> jack = session.query(User).\
- ... options(joinedload('addresses')).\
- ... filter_by(name='jack').all()
- SELECT addresses_1.id AS addresses_1_id, addresses_1.email_address AS addresses_1_email_address,
- addresses_1.user_id AS addresses_1_user_id, users.id AS users_id, users.name AS users_name,
- users.fullname AS users_fullname, users.password AS users_password
- FROM users LEFT OUTER JOIN addresses AS addresses_1 ON users.id = addresses_1.user_id
- WHERE users.name = ?
- ['jack']
+ from sqlalchemy.orm import lazyload
+ # force lazy loading for an attribute that is set to
+ # load some other way normally
+ session.query(User).options(lazyload(User.addresses))
-In addition to "joined eager loading", a second option for eager loading
-exists, called "subquery eager loading". This kind of eager loading emits an
-additional SQL statement for each collection requested, aggregated across all
-parent objects:
+.. _prevent_lazy_with_raiseload:
-.. sourcecode:: python+sql
-
- {sql}>>> jack = session.query(User).\
- ... options(subqueryload('addresses')).\
- ... filter_by(name='jack').all()
- SELECT users.id AS users_id, users.name AS users_name, users.fullname AS users_fullname,
- users.password AS users_password
- FROM users
- WHERE users.name = ?
- ('jack',)
- SELECT addresses.id AS addresses_id, addresses.email_address AS addresses_email_address,
- addresses.user_id AS addresses_user_id, anon_1.users_id AS anon_1_users_id
- FROM (SELECT users.id AS users_id
- FROM users
- WHERE users.name = ?) AS anon_1 JOIN addresses ON anon_1.users_id = addresses.user_id
- ORDER BY anon_1.users_id, addresses.id
- ('jack',)
+Preventing unwanted lazy loads using raiseload
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
-The default **loader strategy** for any :func:`~sqlalchemy.orm.relationship`
-is configured by the ``lazy`` keyword argument, which defaults to ``select`` - this indicates
-a "select" statement .
-Below we set it as ``joined`` so that the ``children`` relationship is eager
-loaded using a JOIN::
+The :func:`.lazyload` strategy produces an effect that is one of the most
+common issues referred to in object relational mapping; the
+:term:`N plus one problem`, which states that for any N objects loaded,
+accessing their lazy-loaded attributes means there will be N+1 SELECT
+statements emitted. In SQLAlchemy, the usual mitigation for the N+1 problem
+is to make use of its very capable eager load system. However, eager loading
+requires that the attributes which are to be loaded be specified with the
+:class:`.Query` up front. The problem of code that may access other attributes
+that were not eagerly loaded, where lazy loading is not desired, may be
+addressed using the :func:`.raiseload` strategy; this loader strategy
+replaces the behavior of lazy loading with an informative error being
+raised::
- # load the 'children' collection using LEFT OUTER JOIN
- class Parent(Base):
- __tablename__ = 'parent'
+ from sqlalchemy.orm import raiseload
+ session.query(User).options(raiseload(User.addresses))
- id = Column(Integer, primary_key=True)
- children = relationship("Child", lazy='joined')
+Above, a ``User`` object loaded from the above query will not have
+the ``.addresses`` collection loaded; if some code later on attempts to
+access this attribute, an ORM exception is raised.
-We can also set it to eagerly load using a second query for all collections,
-using ``subquery``::
+:func:`.raiseload` may be used with a so-called "wildcard" specifier to
+indicate that all relationships should use this strategy. For example,
+to set up only one attribute as eager loading, and all the rest as raise::
- # load the 'children' collection using a second query which
- # JOINS to a subquery of the original
- class Parent(Base):
- __tablename__ = 'parent'
+ session.query(Order).options(
+ joinedload(Order.items), raiseload('*'))
- id = Column(Integer, primary_key=True)
- children = relationship("Child", lazy='subquery')
+The above wildcard will apply to **all** relationships not just on ``Order``
+besides ``items``, but all those on the ``Item`` objects as well. To set up
+:func:`.raiseload` for only the ``Order`` objects, specify a full
+path with :class:`.orm.Load`::
-When querying, all three choices of loader strategy are available on a
-per-query basis, using the :func:`~sqlalchemy.orm.joinedload`,
-:func:`~sqlalchemy.orm.subqueryload` and :func:`~sqlalchemy.orm.lazyload`
-query options:
+ from sqlalchemy.orm import Load
-.. sourcecode:: python+sql
+ session.query(Order).options(
+ joinedload(Order.items), Load(Order).raiseload('*'))
- # set children to load lazily
- session.query(Parent).options(lazyload('children')).all()
+Conversely, to set up the raise for just the ``Item`` objects::
- # set children to load eagerly with a join
- session.query(Parent).options(joinedload('children')).all()
-
- # set children to load eagerly with a second statement
- session.query(Parent).options(subqueryload('children')).all()
-
-.. _subqueryload_ordering:
-
-The Importance of Ordering
---------------------------
-
-A query which makes use of :func:`.subqueryload` in conjunction with a
-limiting modifier such as :meth:`.Query.first`, :meth:`.Query.limit`,
-or :meth:`.Query.offset` should **always** include :meth:`.Query.order_by`
-against unique column(s) such as the primary key, so that the additional queries
-emitted by :func:`.subqueryload` include
-the same ordering as used by the parent query. Without it, there is a chance
-that the inner query could return the wrong rows::
-
- # incorrect, no ORDER BY
- session.query(User).options(subqueryload(User.addresses)).first()
-
- # incorrect if User.name is not unique
- session.query(User).options(subqueryload(User.addresses)).order_by(User.name).first()
-
- # correct
- session.query(User).options(subqueryload(User.addresses)).order_by(User.name, User.id).first()
+ session.query(Order).options(
+ joinedload(Order.items).raiseload('*'))
.. seealso::
- :ref:`faq_subqueryload_limit_sort` - detailed example
+ :ref:`wildcard_loader_strategies`
-Loading Along Paths
--------------------
+.. _joined_eager_loading:
-To reference a relationship that is deeper than one level, method chaining
-may be used. The object returned by all loader options is an instance of
-the :class:`.Load` class, which provides a so-called "generative" interface::
+Joined Eager Loading
+--------------------
- session.query(Parent).options(
- joinedload('foo').
- joinedload('bar').
- joinedload('bat')
- ).all()
+Joined eager loading is the most fundamental style of eager loading in the
+ORM. It works by connecting a JOIN (by default
+a LEFT OUTER join) to the SELECT statement emitted by a :class:`.Query`
+and populates the target scalar/collection from the
+same result set as that of the parent.
-Using method chaining, the loader style of each link in the path is explicitly
-stated. To navigate along a path without changing the existing loader style
-of a particular attribute, the :func:`.defaultload` method/function may be used::
+At the mapping level, this looks like::
- session.query(A).options(
- defaultload("atob").joinedload("btoc")
- ).all()
-
-.. versionchanged:: 0.9.0
- The previous approach of specifying dot-separated paths within loader
- options has been superseded by the less ambiguous approach of the
- :class:`.Load` object and related methods. With this system, the user
- specifies the style of loading for each link along the chain explicitly,
- rather than guessing between options like ``joinedload()`` vs. ``joinedload_all()``.
- The :func:`.orm.defaultload` is provided to allow path navigation without
- modification of existing loader options. The dot-separated path system
- as well as the ``_all()`` functions will remain available for backwards-
- compatibility indefinitely.
+ class Address(Base):
+ # ...
-Polymorphic Eager Loading
--------------------------
+ user = relationship(User, lazy="joined")
-Specification of polymorpic options on a per-eager-load basis is supported.
-See the section :ref:`eagerloading_polymorphic_subtypes` for examples
-of the :meth:`.PropComparator.of_type` method in conjunction with the
-:func:`.orm.with_polymorphic` function.
-
-Default Loading Strategies
---------------------------
+Joined eager loading is usually applied as an option to a query, rather than
+as a default loading option on the mapping, in particular when used for
+collections rather than many-to-one-references. This is achieved
+using the :func:`.joinedload` loader option:
-.. versionadded:: 0.7.5
- Default loader strategies as a new feature.
+.. sourcecode:: python+sql
-Each of :func:`.joinedload`, :func:`.subqueryload`, :func:`.lazyload`,
-:func:`.noload`, and :func:`.raiseload` can be used to set the default
-style of :func:`.relationship` loading
-for a particular query, affecting all :func:`.relationship` -mapped
-attributes not otherwise
-specified in the :class:`.Query`. This feature is available by passing
-the string ``'*'`` as the argument to any of these options::
+ >>> jack = session.query(User).\
+ ... options(joinedload(User.addresses)).\
+ ... filter_by(name='jack').all()
+ {opensql}SELECT
+ addresses_1.id AS addresses_1_id,
+ addresses_1.email_address AS addresses_1_email_address,
+ addresses_1.user_id AS addresses_1_user_id,
+ users.id AS users_id, users.name AS users_name,
+ users.fullname AS users_fullname,
+ users.password AS users_password
+ FROM users
+ LEFT OUTER JOIN addresses AS addresses_1
+ ON users.id = addresses_1.user_id
+ WHERE users.name = ?
+ ['jack']
- session.query(MyClass).options(lazyload('*'))
-Above, the ``lazyload('*')`` option will supersede the ``lazy`` setting
-of all :func:`.relationship` constructs in use for that query,
-except for those which use the ``'dynamic'`` style of loading.
-If some relationships specify
-``lazy='joined'`` or ``lazy='subquery'``, for example,
-using ``lazyload('*')`` will unilaterally
-cause all those relationships to use ``'select'`` loading, e.g. emit a
-SELECT statement when each attribute is accessed.
+The JOIN emitted by default is a LEFT OUTER JOIN, to allow for a lead object
+that does not refer to a related row. For an attribute that is guaranteed
+to have an element, such as a many-to-one
+reference to a related object where the referencing foriegn key is NOT NULL,
+the query can be made more efficient by using an inner join; this is available
+at the mapping level via the :paramref:`.relationship.innerjoin` flag::
-The option does not supersede loader options stated in the
-query, such as :func:`.eagerload`,
-:func:`.subqueryload`, etc. The query below will still use joined loading
-for the ``widget`` relationship::
+ class Address(Base):
+ # ...
- session.query(MyClass).options(
- lazyload('*'),
- joinedload(MyClass.widget)
- )
+ user_id = Column(ForeignKey('users.id'), nullable=False)
+ user = relationship(User, lazy="joined", innerjoin=True)
-If multiple ``'*'`` options are passed, the last one overrides
-those previously passed.
+At the query option level, via the :paramref:`.joinedload.innerjoin` flag::
-Per-Entity Default Loading Strategies
--------------------------------------
+ session.query(Address).options(
+ joinedload(Address.user, innerjoin=True))
-.. versionadded:: 0.9.0
- Per-entity default loader strategies.
+The JOIN will right-nest itself when applied in a chain that includes
+an OUTER JOIN:
-A variant of the default loader strategy is the ability to set the strategy
-on a per-entity basis. For example, if querying for ``User`` and ``Address``,
-we can instruct all relationships on ``Address`` only to use lazy loading
-by first applying the :class:`.Load` object, then specifying the ``*`` as a
-chained option::
+.. sourcecode:: python+sql
- session.query(User, Address).options(Load(Address).lazyload('*'))
+ >>> session.query(User).options(
+ ... joinedload(User.addresses).
+ ... joinedload(Address.widgets, innerjoin=True)).all()
+ {opensql}SELECT
+ widgets_1.id AS widgets_1_id,
+ widgets_1.name AS widgets_1_name,
+ addresses_1.id AS addresses_1_id,
+ addresses_1.email_address AS addresses_1_email_address,
+ addresses_1.user_id AS addresses_1_user_id,
+ users.id AS users_id, users.name AS users_name,
+ users.fullname AS users_fullname,
+ users.password AS users_password
+ FROM users
+ LEFT OUTER JOIN (
+ addresses AS addresses_1 JOIN widgets AS widgets_1 ON
+ addresses_1.widget_id = widgets_1.id
+ ) ON users.id = addresses_1.user_id
+
+On older versions of SQLite, the above nested right JOIN may be re-rendered
+as a nested subquery. Older versions of SQLAlchemy would convert right-nested
+joins into subuqeries in all cases.
+
+Joined eager loading and result set batching
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+A central concept of joined eager loading when applied to collections is that
+the :class:`.Query` object must de-duplicate rows against the leading
+entity being queried. Such as above,
+if the ``User`` object we loaded referred to three ``Address`` objects, the
+result of the SQL statement would have had three rows; yet the :class:`.Query`
+returns only one ``User`` object. As additional rows are received for a
+``User`` object just loaded in a previous row, the additional columns that
+refer to new ``Address`` objects are directed into additional results within
+the ``User.addresses`` collection of that particular object.
+
+This process is very transparent, however does imply that joined eager
+loading is incompatible with "batched" query results, provided by the
+:meth:`.Query.yield_per` method, when used for collection loading. Joined
+eager loading used for scalar references is however compatible with
+:meth:`.Query.yield_per`. The :meth:`.Query.yield_per` method will result
+in an exception thrown if a collection based joined eager loader is
+in play.
+
+To "batch" queries with arbitrarily large sets of result data while maintaining
+compatibility with collection-based joined eager loading, emit multiple
+SELECT statements, each referring to a subset of rows using the WHERE
+clause, e.g. windowing.
-Above, all relationships on ``Address`` will be set to a lazy load.
.. _zen_of_eager_loading:
-The Zen of Eager Loading
--------------------------
-
-The philosophy behind loader strategies is that any set of loading schemes can be
-applied to a particular query, and *the results don't change* - only the number
-of SQL statements required to fully load related objects and collections changes. A particular
-query might start out using all lazy loads. After using it in context, it might be revealed
-that particular attributes or collections are always accessed, and that it would be more
-efficient to change the loader strategy for these. The strategy can be changed with no other
-modifications to the query, the results will remain identical, but fewer SQL statements would be emitted.
-In theory (and pretty much in practice), nothing you can do to the :class:`.Query` would make it load
-a different set of primary or related objects based on a change in loader strategy.
+The Zen of Joined Eager Loading
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+Since joined eager loading seems to have many resemblences to the use of
+:meth:`.Query.join`, it often produces confusion as to when and how it should
+be used. It is critical to understand the distinction that while
+:meth:`.Query.join` is used to alter the results of a query, :func:`.joinedload`
+goes through great lengths to **not** alter the results of the query, and
+instead hide the effects of the rendered join to only allow for related objects
+to be present.
+
+The philosophy behind loader strategies is that any set of loading schemes can
+be applied to a particular query, and *the results don't change* - only the
+number of SQL statements required to fully load related objects and collections
+changes. A particular query might start out using all lazy loads. After using
+it in context, it might be revealed that particular attributes or collections
+are always accessed, and that it would be more efficient to change the loader
+strategy for these. The strategy can be changed with no other modifications
+to the query, the results will remain identical, but fewer SQL statements would
+be emitted. In theory (and pretty much in practice), nothing you can do to the
+:class:`.Query` would make it load a different set of primary or related
+objects based on a change in loader strategy.
How :func:`joinedload` in particular achieves this result of not impacting
-entity rows returned in any way is that it creates an anonymous alias of the joins it adds to your
-query, so that they can't be referenced by other parts of the query. For example,
-the query below uses :func:`.joinedload` to create a LEFT OUTER JOIN from ``users``
-to ``addresses``, however the ``ORDER BY`` added against ``Address.email_address``
-is not valid - the ``Address`` entity is not named in the query:
+entity rows returned in any way is that it creates an anonymous alias of the
+joins it adds to your query, so that they can't be referenced by other parts of
+the query. For example, the query below uses :func:`.joinedload` to create a
+LEFT OUTER JOIN from ``users`` to ``addresses``, however the ``ORDER BY`` added
+against ``Address.email_address`` is not valid - the ``Address`` entity is not
+named in the query:
.. sourcecode:: python+sql
... options(joinedload(User.addresses)).\
... filter(User.name=='jack').\
... order_by(Address.email_address).all()
- {opensql}SELECT addresses_1.id AS addresses_1_id, addresses_1.email_address AS addresses_1_email_address,
- addresses_1.user_id AS addresses_1_user_id, users.id AS users_id, users.name AS users_name,
- users.fullname AS users_fullname, users.password AS users_password
- FROM users LEFT OUTER JOIN addresses AS addresses_1 ON users.id = addresses_1.user_id
- WHERE users.name = ? ORDER BY addresses.email_address <-- this part is wrong !
+ {opensql}SELECT
+ addresses_1.id AS addresses_1_id,
+ addresses_1.email_address AS addresses_1_email_address,
+ addresses_1.user_id AS addresses_1_user_id,
+ users.id AS users_id,
+ users.name AS users_name,
+ users.fullname AS users_fullname,
+ users.password AS users_password
+ FROM users
+ LEFT OUTER JOIN addresses AS addresses_1
+ ON users.id = addresses_1.user_id
+ WHERE users.name = ?
+ ORDER BY addresses.email_address <-- this part is wrong !
['jack']
Above, ``ORDER BY addresses.email_address`` is not valid since ``addresses`` is not in the
... filter(User.name=='jack').\
... order_by(Address.email_address).all()
{opensql}
- SELECT users.id AS users_id, users.name AS users_name,
- users.fullname AS users_fullname, users.password AS users_password
- FROM users JOIN addresses ON users.id = addresses.user_id
- WHERE users.name = ? ORDER BY addresses.email_address
+ SELECT
+ users.id AS users_id,
+ users.name AS users_name,
+ users.fullname AS users_fullname,
+ users.password AS users_password
+ FROM users
+ JOIN addresses ON users.id = addresses.user_id
+ WHERE users.name = ?
+ ORDER BY addresses.email_address
['jack']
-The statement above is of course not the same as the previous one, in that the columns from ``addresses``
-are not included in the result at all. We can add :func:`.joinedload` back in, so that
-there are two joins - one is that which we are ordering on, the other is used anonymously to
-load the contents of the ``User.addresses`` collection:
+The statement above is of course not the same as the previous one, in that the
+columns from ``addresses`` are not included in the result at all. We can add
+:func:`.joinedload` back in, so that there are two joins - one is that which we
+are ordering on, the other is used anonymously to load the contents of the
+``User.addresses`` collection:
.. sourcecode:: python+sql
... options(joinedload(User.addresses)).\
... filter(User.name=='jack').\
... order_by(Address.email_address).all()
- {opensql}SELECT addresses_1.id AS addresses_1_id, addresses_1.email_address AS addresses_1_email_address,
- addresses_1.user_id AS addresses_1_user_id, users.id AS users_id, users.name AS users_name,
- users.fullname AS users_fullname, users.password AS users_password
- FROM users JOIN addresses ON users.id = addresses.user_id
- LEFT OUTER JOIN addresses AS addresses_1 ON users.id = addresses_1.user_id
- WHERE users.name = ? ORDER BY addresses.email_address
+ {opensql}SELECT
+ addresses_1.id AS addresses_1_id,
+ addresses_1.email_address AS addresses_1_email_address,
+ addresses_1.user_id AS addresses_1_user_id,
+ users.id AS users_id, users.name AS users_name,
+ users.fullname AS users_fullname,
+ users.password AS users_password
+ FROM users JOIN addresses
+ ON users.id = addresses.user_id
+ LEFT OUTER JOIN addresses AS addresses_1
+ ON users.id = addresses_1.user_id
+ WHERE users.name = ?
+ ORDER BY addresses.email_address
['jack']
-What we see above is that our usage of :meth:`.Query.join` is to supply JOIN clauses we'd like
-to use in subsequent query criterion, whereas our usage of :func:`.joinedload` only concerns
-itself with the loading of the ``User.addresses`` collection, for each ``User`` in the result.
-In this case, the two joins most probably appear redundant - which they are. If we
-wanted to use just one JOIN for collection loading as well as ordering, we use the
+What we see above is that our usage of :meth:`.Query.join` is to supply JOIN
+clauses we'd like to use in subsequent query criterion, whereas our usage of
+:func:`.joinedload` only concerns itself with the loading of the
+``User.addresses`` collection, for each ``User`` in the result. In this case,
+the two joins most probably appear redundant - which they are. If we wanted to
+use just one JOIN for collection loading as well as ordering, we use the
:func:`.contains_eager` option, described in :ref:`contains_eager` below. But
-to see why :func:`joinedload` does what it does, consider if we were **filtering** on a
-particular ``Address``:
+to see why :func:`joinedload` does what it does, consider if we were
+**filtering** on a particular ``Address``:
.. sourcecode:: python+sql
... filter(User.name=='jack').\
... filter(Address.email_address=='someaddress@foo.com').\
... all()
- {opensql}SELECT addresses_1.id AS addresses_1_id, addresses_1.email_address AS addresses_1_email_address,
- addresses_1.user_id AS addresses_1_user_id, users.id AS users_id, users.name AS users_name,
- users.fullname AS users_fullname, users.password AS users_password
- FROM users JOIN addresses ON users.id = addresses.user_id
- LEFT OUTER JOIN addresses AS addresses_1 ON users.id = addresses_1.user_id
+ {opensql}SELECT
+ addresses_1.id AS addresses_1_id,
+ addresses_1.email_address AS addresses_1_email_address,
+ addresses_1.user_id AS addresses_1_user_id,
+ users.id AS users_id, users.name AS users_name,
+ users.fullname AS users_fullname,
+ users.password AS users_password
+ FROM users JOIN addresses
+ ON users.id = addresses.user_id
+ LEFT OUTER JOIN addresses AS addresses_1
+ ON users.id = addresses_1.user_id
WHERE users.name = ? AND addresses.email_address = ?
['jack', 'someaddress@foo.com']
-Above, we can see that the two JOINs have very different roles. One will match exactly
-one row, that of the join of ``User`` and ``Address`` where ``Address.email_address=='someaddress@foo.com'``.
-The other LEFT OUTER JOIN will match *all* ``Address`` rows related to ``User``,
-and is only used to populate the ``User.addresses`` collection, for those ``User`` objects
-that are returned.
+Above, we can see that the two JOINs have very different roles. One will match
+exactly one row, that of the join of ``User`` and ``Address`` where
+``Address.email_address=='someaddress@foo.com'``. The other LEFT OUTER JOIN
+will match *all* ``Address`` rows related to ``User``, and is only used to
+populate the ``User.addresses`` collection, for those ``User`` objects that are
+returned.
-By changing the usage of :func:`.joinedload` to another style of loading, we can change
-how the collection is loaded completely independently of SQL used to retrieve
-the actual ``User`` rows we want. Below we change :func:`.joinedload` into
-:func:`.subqueryload`:
+By changing the usage of :func:`.joinedload` to another style of loading, we
+can change how the collection is loaded completely independently of SQL used to
+retrieve the actual ``User`` rows we want. Below we change :func:`.joinedload`
+into :func:`.subqueryload`:
.. sourcecode:: python+sql
... filter(User.name=='jack').\
... filter(Address.email_address=='someaddress@foo.com').\
... all()
- {opensql}SELECT users.id AS users_id, users.name AS users_name,
- users.fullname AS users_fullname, users.password AS users_password
- FROM users JOIN addresses ON users.id = addresses.user_id
- WHERE users.name = ? AND addresses.email_address = ?
+ {opensql}SELECT
+ users.id AS users_id,
+ users.name AS users_name,
+ users.fullname AS users_fullname,
+ users.password AS users_password
+ FROM users
+ JOIN addresses ON users.id = addresses.user_id
+ WHERE
+ users.name = ?
+ AND addresses.email_address = ?
['jack', 'someaddress@foo.com']
# ... subqueryload() emits a SELECT in order
# to load all address records ...
-When using joined eager loading, if the
-query contains a modifier that impacts the rows returned
-externally to the joins, such as when using DISTINCT, LIMIT, OFFSET
-or equivalent, the completed statement is first
-wrapped inside a subquery, and the joins used specifically for joined eager
-loading are applied to the subquery. SQLAlchemy's
-joined eager loading goes the extra mile, and then ten miles further, to
-absolutely ensure that it does not affect the end result of the query, only
-the way collections and related objects are loaded, no matter what the format of the query is.
+When using joined eager loading, if the query contains a modifier that impacts
+the rows returned externally to the joins, such as when using DISTINCT, LIMIT,
+OFFSET or equivalent, the completed statement is first wrapped inside a
+subquery, and the joins used specifically for joined eager loading are applied
+to the subquery. SQLAlchemy's joined eager loading goes the extra mile, and
+then ten miles further, to absolutely ensure that it does not affect the end
+result of the query, only the way collections and related objects are loaded,
+no matter what the format of the query is.
+
+.. seealso::
+
+ :ref:`contains_eager` - using :func:`.contains_eager`
+
+.. _subquery_eager_loading:
+
+Subquery Eager Loading
+----------------------
+
+Subqueryload eager loading is configured in the same manner as that of
+joined eager loading; for the :paramref:`.relationship.lazy` parameter,
+we would specify ``"subquery"`` rather than ``"joined"``, and for
+the option we use the :func:`.subqueryload` option rather than the
+:func:`.joinedload` option.
+
+The operation of subquery eager loading is to emit a second SELECT statement
+for each relationship to be loaded, across all result objects at once.
+This SELECT statement refers to the original SELECT statement, wrapped
+inside of a subquery, so that we retrieve the same list of primary keys
+for the primary object being returned, then link that to the sum of all
+the collection members to load them at once:
+
+.. sourcecode:: python+sql
+
+ >>> jack = session.query(User).\
+ ... options(subqueryload(User.addresses)).\
+ ... filter_by(name='jack').all()
+ {opensql}SELECT
+ users.id AS users_id,
+ users.name AS users_name,
+ users.fullname AS users_fullname,
+ users.password AS users_password
+ FROM users
+ WHERE users.name = ?
+ ('jack',)
+ SELECT
+ addresses.id AS addresses_id,
+ addresses.email_address AS addresses_email_address,
+ addresses.user_id AS addresses_user_id,
+ anon_1.users_id AS anon_1_users_id
+ FROM (
+ SELECT users.id AS users_id
+ FROM users
+ WHERE users.name = ?) AS anon_1
+ JOIN addresses ON anon_1.users_id = addresses.user_id
+ ORDER BY anon_1.users_id, addresses.id
+ ('jack',)
+
+The subqueryload strategy has many advantages over joined eager loading
+in the area of loading collections. First, it allows the original query
+to proceed without changing it at all, not introducing in particular a
+LEFT OUTER JOIN that may make it less efficient. Secondly, it allows
+for many collections to be eagerly loaded without producing a single query
+that has many JOINs in it, which can be even less efficient; each relationship
+is loaded in a fully separate query. Finally, because the additional query
+only needs to load the collection items and not the lead object, it can
+use an inner JOIN in all cases for greater query efficiency.
+
+Disadvantages of subqueryload include that the complexity of the original
+query is transferred to the relationship queries, which when combined with the
+use of a subquery, can on some backends in some cases (notably MySQL) produce
+significantly slow queries. Additionally, the subqueryload strategy can only
+load the full contents of all collections at once, is therefore incompatible
+with "batched" loading supplied by :meth:`.Query.yield_per`, both for collection
+and scalar relationships.
+
+
+.. _subqueryload_ordering:
+
+The Importance of Ordering
+^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+A query which makes use of :func:`.subqueryload` in conjunction with a
+limiting modifier such as :meth:`.Query.first`, :meth:`.Query.limit`,
+or :meth:`.Query.offset` should **always** include :meth:`.Query.order_by`
+against unique column(s) such as the primary key, so that the additional queries
+emitted by :func:`.subqueryload` include
+the same ordering as used by the parent query. Without it, there is a chance
+that the inner query could return the wrong rows::
+
+ # incorrect, no ORDER BY
+ session.query(User).options(
+ subqueryload(User.addresses)).first()
+
+ # incorrect if User.name is not unique
+ session.query(User).options(
+ subqueryload(User.addresses)
+ ).order_by(User.name).first()
+
+ # correct
+ session.query(User).options(
+ subqueryload(User.addresses)
+ ).order_by(User.name, User.id).first()
+
+.. seealso::
+
+ :ref:`faq_subqueryload_limit_sort` - detailed example
+
.. _what_kind_of_loading:
any case. Therefore joined eager loading only makes sense when the size of the collections are
relatively small. The LEFT OUTER JOIN can also be performance intensive compared to an INNER join.
- * When using subquery loading, the load of 100 objects will emit two SQL statements. The second
- statement will fetch a total number of rows equal to the sum of the size of all collections. An
- INNER JOIN is used, and a minimum of parent columns are requested, only the primary keys. So a
- subquery load makes sense when the collections are larger.
+ * When using subquery loading, the load of 100 objects will
+ emit two SQL statements. The second statement will fetch a total number of
+ rows equal to the sum of the size of all collections. An INNER JOIN is
+ used, and a minimum of parent columns are requested, only the primary keys.
+ So a subquery load makes sense when the collections are larger.
* When multiple levels of depth are used with joined or subquery loading, loading collections-within-
- collections will multiply the total number of rows fetched in a cartesian fashion. Both forms
- of eager loading always join from the original parent class.
+ collections will multiply the total number of rows fetched in a cartesian fashion. Both
+ joined and subquery eager loading always join from the original parent class; if loading a collection
+ four levels deep, there will be four JOINs out to the parent.
* Many to One Reference
joined loading, however, except perhaps that subquery loading can use an INNER JOIN in all cases
whereas joined loading requires that the foreign key is NOT NULL.
+
+Polymorphic Eager Loading
+-------------------------
+
+Specification of polymorpic options on a per-eager-load basis is supported.
+See the section :ref:`eagerloading_polymorphic_subtypes` for examples
+of the :meth:`.PropComparator.of_type` method in conjunction with the
+:func:`.orm.with_polymorphic` function.
+
+.. _wildcard_loader_strategies:
+
+Wildcard Loading Strategies
+---------------------------
+
+Each of :func:`.joinedload`, :func:`.subqueryload`, :func:`.lazyload`,
+:func:`.noload`, and :func:`.raiseload` can be used to set the default
+style of :func:`.relationship` loading
+for a particular query, affecting all :func:`.relationship` -mapped
+attributes not otherwise
+specified in the :class:`.Query`. This feature is available by passing
+the string ``'*'`` as the argument to any of these options::
+
+ session.query(MyClass).options(lazyload('*'))
+
+Above, the ``lazyload('*')`` option will supersede the ``lazy`` setting
+of all :func:`.relationship` constructs in use for that query,
+except for those which use the ``'dynamic'`` style of loading.
+If some relationships specify
+``lazy='joined'`` or ``lazy='subquery'``, for example,
+using ``lazyload('*')`` will unilaterally
+cause all those relationships to use ``'select'`` loading, e.g. emit a
+SELECT statement when each attribute is accessed.
+
+The option does not supersede loader options stated in the
+query, such as :func:`.eagerload`,
+:func:`.subqueryload`, etc. The query below will still use joined loading
+for the ``widget`` relationship::
+
+ session.query(MyClass).options(
+ lazyload('*'),
+ joinedload(MyClass.widget)
+ )
+
+If multiple ``'*'`` options are passed, the last one overrides
+those previously passed.
+
+Per-Entity Wildcard Loading Strategies
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+A variant of the wildcard loader strategy is the ability to set the strategy
+on a per-entity basis. For example, if querying for ``User`` and ``Address``,
+we can instruct all relationships on ``Address`` only to use lazy loading
+by first applying the :class:`.Load` object, then specifying the ``*`` as a
+chained option::
+
+ session.query(User, Address).options(
+ Load(Address).lazyload('*'))
+
+Above, all relationships on ``Address`` will be set to a lazy load.
+
.. _joinedload_and_join:
.. _contains_eager:
options(contains_eager(User.addresses, alias=adalias))
# get results normally
- {sql}r = query.all()
- SELECT users.user_id AS users_user_id, users.user_name AS users_user_name, adalias.address_id AS adalias_address_id,
- adalias.user_id AS adalias_user_id, adalias.email_address AS adalias_email_address, (...other columns...)
- FROM users LEFT OUTER JOIN email_addresses AS email_addresses_1 ON users.user_id = email_addresses_1.user_id
+ r = query.all()
+ {opensql}SELECT
+ users.user_id AS users_user_id,
+ users.user_name AS users_user_name,
+ adalias.address_id AS adalias_address_id,
+ adalias.user_id AS adalias_user_id,
+ adalias.email_address AS adalias_email_address,
+ (...other columns...)
+ FROM users
+ LEFT OUTER JOIN email_addresses AS email_addresses_1
+ ON users.user_id = email_addresses_1.user_id
The path given as the argument to :func:`.contains_eager` needs
to be a full path from the starting entity. For example if we were loading
``Users->orders->Order->items->Item``, the string version would look like::
- query(User).options(contains_eager('orders').contains_eager('items'))
+ query(User).options(
+ contains_eager('orders').
+ contains_eager('items'))
Or using the class-bound descriptor::
- query(User).options(contains_eager(User.orders).contains_eager(Order.items))
+ query(User).options(
+ contains_eager(User.orders).
+ contains_eager(Order.items))
Using contains_eager() to load a custom-filtered collection result
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
# label the columns of the addresses table
eager_columns = select([
- addresses.c.address_id.label('a1'),
- addresses.c.email_address.label('a2'),
- addresses.c.user_id.label('a3')])
+ addresses.c.address_id.label('a1'),
+ addresses.c.email_address.label('a2'),
+ addresses.c.user_id.label('a3')
+ ])
# select from a raw SQL statement which uses those label names for the
# addresses table. contains_eager() matches them up.
query = session.query(User).\
from_statement("select users.*, addresses.address_id as a1, "
- "addresses.email_address as a2, addresses.user_id as a3 "
- "from users left outer join addresses on users.user_id=addresses.user_id").\
+ "addresses.email_address as a2, "
+ "addresses.user_id as a3 "
+ "from users left outer join "
+ "addresses on users.user_id=addresses.user_id").\
options(contains_eager(User.addresses, alias=eager_columns))
Creating Custom Load Rules
__tablename__ = 'a'
id = Column(Integer, primary_key=True)
b_id = Column(ForeignKey('b.id'))
- b = relationship("B", backref=backref("a", uselist=False), lazy='joined')
+ b = relationship(
+ "B",
+ backref=backref("a", uselist=False),
+ lazy='joined')
class B(Base):
.. sourcecode:: pycon+sql
- {sql}a1 = s.query(A).first()
- SELECT a.id AS a_id, a.b_id AS a_b_id, b_1.id AS b_1_id
- FROM a LEFT OUTER JOIN b AS b_1 ON b_1.id = a.b_id
+ a1 = s.query(A).first()
+ {opensql}SELECT
+ a.id AS a_id,
+ a.b_id AS a_b_id,
+ b_1.id AS b_1_id
+ FROM a
+ LEFT OUTER JOIN b AS b_1 ON b_1.id = a.b_id
LIMIT ? OFFSET ?
(1, 0)
{stop}assert a1.b.a is a1
.. autofunction:: lazyload
+.. autoclass:: Load
+
.. autofunction:: noload
.. autofunction:: raiseload