From: Mike Bayer Date: Mon, 16 Jan 2023 21:02:07 +0000 (-0500) Subject: apply changelog note for change of column loader options X-Git-Tag: rel_1_4_47~18 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=1762c40490182fc511b71f5044f7252e2937162b;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git apply changelog note for change of column loader options Change-Id: Ib9a69e20420e1fda755f4533c5f90bc08ba11b48 References: #8879 References: #9101 (cherry picked from commit 5e6cb26a017fb72bc3f925194c6f8c1eda968fbe) --- diff --git a/doc/build/changelog/migration_14.rst b/doc/build/changelog/migration_14.rst index 089715bf6d..85c8c1d3f3 100644 --- a/doc/build/changelog/migration_14.rst +++ b/doc/build/changelog/migration_14.rst @@ -2280,6 +2280,175 @@ to be more noticeable. :ticket:`1763` +.. _change_8879: + +Column loaders such as ``deferred()``, ``with_expression()`` only take effect when indicated on the outermost, full entity query +-------------------------------------------------------------------------------------------------------------------------------- + +.. note:: This change note was not present in earlier versions of this document, + however is relevant for all SQLAlchemy 1.4 versions. + +A behavior that was never supported in 1.3 and previous versions +yet nonetheless would have a particular effect +was to repurpose column loader options such as :func:`_orm.defer` and +:func:`_orm.with_expression` in subqueries in order to control which +SQL expressions would be in the columns clause of each subquery. A typical +example would be to +construct UNION queries, such as:: + + q1 = session.query(User).options(with_expression(User.expr, literal("u1"))) + q2 = session.query(User).options(with_expression(User.expr, literal("u2"))) + + q1.union_all(q2).all() + +In version 1.3, the :func:`_orm.with_expression` option would take effect +for each element of the UNION, such as: + +.. sourcecode:: sql + + SELECT anon_1.anon_2 AS anon_1_anon_2, anon_1.user_account_id AS anon_1_user_account_id, + anon_1.user_account_name AS anon_1_user_account_name + FROM ( + SELECT ? AS anon_2, user_account.id AS user_account_id, user_account.name AS user_account_name + FROM user_account + UNION ALL + SELECT ? AS anon_3, user_account.id AS user_account_id, user_account.name AS user_account_name + FROM user_account + ) AS anon_1 + ('u1', 'u2') + +SQLAlchemy 1.4's notion of loader options has been made more strict, and as such +are applied to the **outermost part of the query only**, which is the +SELECT that is intended to populate the actual ORM entities to be returned; the +query above in 1.4 will produce: + +.. sourcecode:: sql + + SELECT ? AS anon_1, anon_2.user_account_id AS anon_2_user_account_id, + anon_2.user_account_name AS anon_2_user_account_name + FROM ( + SELECT user_account.id AS user_account_id, user_account.name AS user_account_name + FROM user_account + UNION ALL + SELECT user_account.id AS user_account_id, user_account.name AS user_account_name + FROM user_account + ) AS anon_2 + ('u1',) + +that is, the options for the :class:`_orm.Query` were taken from the first +element of the UNION, since all loader options are only to be at the topmost +level. The option from the second query was ignored. + +Rationale +^^^^^^^^^ + +This behavior now more closely matches that of other kinds of loader options +such as relationship loader options like :func:`_orm.joinedload` in all +SQLAlchemy versions, 1.3 and earlier included, which in a UNION situation were +already copied out to the top most level of the query, and only taken from the +first element of the UNION, discarding any options on other parts of the query. + +This implicit copying and selective ignoring of options, demonstrated above as +being fairly arbitrary, is a legacy behavior that's only part of +:class:`_orm.Query`, and is a particular example of where :class:`_orm.Query` +and its means of applying :meth:`_orm.Query.union_all` falls short, as it's +ambiguous how to turn a single SELECT into a UNION of itself and another query +and how loader options should be applied to that new statement. + +SQLAlchemy 1.4's behavior can be demonstrated as generally superior to that +of 1.3 for a more common case of using :func:`_orm.defer`. The following +query:: + + q1 = session.query(User).options(defer(User.name)) + q2 = session.query(User).options(defer(User.name)) + + q1.union_all(q2).all() + +In 1.3 would awkwardly add NULL to the inner queries and then SELECT it: + +.. sourcecode:: sql + + SELECT anon_1.anon_2 AS anon_1_anon_2, anon_1.user_account_id AS anon_1_user_account_id + FROM ( + SELECT NULL AS anon_2, user_account.id AS user_account_id + FROM user_account + UNION ALL + SELECT NULL AS anon_2, user_account.id AS user_account_id + FROM user_account + ) AS anon_1 + +If all queries didn't have the identical options set up, the above scenario +would raise an error due to not being able to form a proper UNION. + +Whereas in 1.4, the option is applied only at the top layer, omitting +the fetch for ``User.name``, and this complexity is avoided: + +.. sourcecode:: sql + + SELECT anon_1.user_account_id AS anon_1_user_account_id + FROM ( + SELECT user_account.id AS user_account_id, user_account.name AS user_account_name + FROM user_account + UNION ALL + SELECT user_account.id AS user_account_id, user_account.name AS user_account_name + FROM user_account + ) AS anon_1 + +Correct Approach +^^^^^^^^^^^^^^^^ + +Using :term:`2.0-style` querying, no warning is emitted at the moment, however +the nested :func:`_orm.with_expression` options are consistently ignored as +they don't apply to an entity being loaded, and are not implicitly copied +anywhere. The query below produces no output for the +:func:`_orm.with_expression` calls:: + + s1 = select(User).options(with_expression(User.expr, literal("u1"))) + s2 = select(User).options(with_expression(User.expr, literal("u2"))) + + stmt = union_all(s1, s2) + + session.scalars(select(User).from_statement(stmt)).all() + +producing the SQL: + +.. sourcecode:: sql + + SELECT user_account.id, user_account.name + FROM user_account + UNION ALL + SELECT user_account.id, user_account.name + FROM user_account + +To correctly apply :func:`_orm.with_expression` to the ``User`` entity, +it should be applied to the outermost level of the query, using an +ordinary SQL expression inside the columns clause of each SELECT:: + + s1 = select(User, literal("u1").label("some_literal")) + s2 = select(User, literal("u2").label("some_literal")) + + stmt = union_all(s1, s2) + + session.scalars( + select(User) + .from_statement(stmt) + .options(with_expression(User.expr, stmt.selected_columns.some_literal)) + ).all() + +Which will produce the expected SQL: + +.. sourcecode:: sql + + SELECT user_account.id, user_account.name, ? AS some_literal + FROM user_account + UNION ALL + SELECT user_account.id, user_account.name, ? AS some_literal + FROM user_account + +The ``User`` objects themselves will include this expression in their +contents underneath ``User.expr``. + + .. _change_4519: Accessing an uninitialized collection attribute on a transient object no longer mutates __dict__ diff --git a/doc/build/orm/mapped_sql_expr.rst b/doc/build/orm/mapped_sql_expr.rst index 47af9b22c4..0e93e5e920 100644 --- a/doc/build/orm/mapped_sql_expr.rst +++ b/doc/build/orm/mapped_sql_expr.rst @@ -365,7 +365,17 @@ The :func:`.query_expression` mapping has these caveats: a new :func:`.with_expression` directive will the attribute be set to a non-None value. -* The mapped attribute currently **cannot** be applied to other parts of the +* :func:`_orm.with_expression`, as an object loading option, only takes effect + on the **outermost part + of a query** and only for a query against a full entity, and not for arbitrary + column selects, within subqueries, or the elements of a compound + statement such as a UNION. See the next + section :ref:`mapper_querytime_expression_unions` for an example. + + .. versionchanged:: 1.4 This is new as of version 1.4. See the change notes + at :ref:`change_8879` for background. + +* The mapped attribute **cannot** be applied to other parts of the query, such as the WHERE clause, the ORDER BY clause, and make use of the ad-hoc expression; that is, this won't work:: @@ -391,3 +401,73 @@ The :func:`.query_expression` mapping has these caveats: .. versionadded:: 1.2 + +.. _mapper_querytime_expression_unions: + + +Using ``with_expression()`` with UNIONs, other subqueries +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +The :func:`_orm.with_expression` construct is an ORM loader option, and as +such may only be applied to the outermost level of a SELECT statement which +is to load a particular ORM entity. It does not have any effect if used +inside of a :func:`_sql.select` that will then be used as a subquery or +as an element within a compound statement such as a UNION. + +.. versionchanged:: 1.4 The behavior of column loader options applying + only at the outermost layer of an ORM SELECT statement was previously + not applied consistently; in 1.4 it applies to all loader options + for both columns as well as relationships. Background on this change + is at :ref:`change_8879`. + +In order to use arbitrary SQL expressions in subqueries, normal Core-style +means of adding expressions should be used. To assemble a subquery-derived +expression onto the ORM entity's :func:`_orm.query_expression` attributes, +:func:`_orm.with_expression` is used at the top layer of ORM object loading, +referencing the SQL expression within the subquery. + +.. note:: + + The example below uses :term:`2.0 style` queries in order to demonstrate a + UNION. ORM UNIONs may be assembled without ambiguity using this style + of query. + +In the example below, two :func:`_sql.select` constructs are used against +the ORM entity ``A`` with an additional SQL expression labeled in +``expr``, and combined using :func:`_sql.union_all`. Then, at the topmost +layer, the ``A`` entity is SELECTed from this UNION, using the +querying technique described at :ref:`orm_queryguide_unions`, adding an +option with :func:`_orm.with_expression` to extract this SQL expression +onto newly loaded instances of ``A``: + +.. sourcecode:: pycon+sql + + >>> from sqlalchemy import union_all + >>> s1 = ( + ... select(User, func.count(Book.id).label("book_count")) + ... .join_from(User, Book) + ... .where(User.name == "spongebob") + ... ) + >>> s2 = ( + ... select(User, func.count(Book.id).label("book_count")) + ... .join_from(User, Book) + ... .where(User.name == "sandy") + ... ) + >>> union_stmt = union_all(s1, s2) + >>> orm_stmt = ( + ... select(User) + ... .from_statement(union_stmt) + ... .options(with_expression(User.book_count, union_stmt.c.book_count)) + ... ) + >>> for user in session.scalars(orm_stmt): + ... print(f"Username: {user.name} Number of books: {user.book_count}") + {execsql}SELECT user_account.id, user_account.name, user_account.fullname, count(book.id) AS book_count + FROM user_account JOIN book ON user_account.id = book.owner_id + WHERE user_account.name = ? + UNION ALL + SELECT user_account.id, user_account.name, user_account.fullname, count(book.id) AS book_count + FROM user_account JOIN book ON user_account.id = book.owner_id + WHERE user_account.name = ? + [...] ('spongebob', 'sandy'){stop} + Username: spongebob Number of books: 3 + Username: sandy Number of books: 3 diff --git a/lib/sqlalchemy/orm/strategy_options.py b/lib/sqlalchemy/orm/strategy_options.py index a4fe6f90f8..170847f42e 100644 --- a/lib/sqlalchemy/orm/strategy_options.py +++ b/lib/sqlalchemy/orm/strategy_options.py @@ -1955,10 +1955,17 @@ def with_expression(loadopt, key, expression): .. versionadded:: 1.2 - :param key: Attribute to be undeferred. + :param key: Attribute to be populated. :param expr: SQL expression to be applied to the attribute. + .. versionchanged:: 1.4 Loader options such as + :func:`_orm.with_expression` + take effect only at the **outermost** query used, and should not be used + within subqueries or inner elements of a UNION. See the change notes at + :ref:`change_8879` for background on how to correctly add arbitrary + columns to subqueries. + .. note:: the target attribute is populated only if the target object is **not currently loaded** in the current :class:`_orm.Session` unless the :meth:`_query.Query.populate_existing` method is used.