From: Federico Caselli Date: Mon, 6 Oct 2025 19:39:10 +0000 (+0200) Subject: Support VIRTUAL computed columns on PostgreSQL. X-Git-Url: http://git.ipfire.org/gitweb.cgi?a=commitdiff_plain;h=8d560a0aa522c4cf8518698c44ea842c2640190a;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Support VIRTUAL computed columns on PostgreSQL. Support for ``VIRTUAL`` computed columns on PostgreSQL 18 and later has been added. The default behavior when :paramref:`.Computed.persisted` is not specified has been changed to align with PostgreSQL 18's default of ``VIRTUAL``. When :paramref:`.Computed.persisted` is not specified, no keyword is rendered on PostgreSQL 18 and later; on older versions a warning is emitted and ``STORED`` is used as the default. To explicitly request ``STORED`` behavior on all PostgreSQL versions, specify ``persisted=True``. Fixes: #12866 Change-Id: Ic2ebdbe79e230a88370cf2b3503d2d1815f72a39 --- diff --git a/doc/build/changelog/unreleased_21/12866.rst b/doc/build/changelog/unreleased_21/12866.rst new file mode 100644 index 0000000000..43f9e85dd5 --- /dev/null +++ b/doc/build/changelog/unreleased_21/12866.rst @@ -0,0 +1,12 @@ +.. change:: + :tags: feature, postgresql + :tickets: 12866 + + Support for ``VIRTUAL`` computed columns on PostgreSQL 18 and later has + been added. The default behavior when :paramref:`.Computed.persisted` is + not specified has been changed to align with PostgreSQL 18's default of + ``VIRTUAL``. When :paramref:`.Computed.persisted` is not specified, no + keyword is rendered on PostgreSQL 18 and later; on older versions a + warning is emitted and ``STORED`` is used as the default. To explicitly + request ``STORED`` behavior on all PostgreSQL versions, specify + ``persisted=True``. diff --git a/doc/build/core/defaults.rst b/doc/build/core/defaults.rst index 70dfed9641..e4e5fb78b9 100644 --- a/doc/build/core/defaults.rst +++ b/doc/build/core/defaults.rst @@ -649,7 +649,7 @@ Example:: Column("perimeter", Integer, Computed("4 * side")), ) -The DDL for the ``square`` table when run on a PostgreSQL 12 backend will look +The DDL for the ``square`` table when run on a PostgreSQL 18 backend [#pgnote]_ will look like: .. sourcecode:: sql @@ -657,8 +657,8 @@ like: CREATE TABLE square ( id SERIAL NOT NULL, side INTEGER, - area INTEGER GENERATED ALWAYS AS (side * side) STORED, - perimeter INTEGER GENERATED ALWAYS AS (4 * side) STORED, + area INTEGER GENERATED ALWAYS AS (side * side), + perimeter INTEGER GENERATED ALWAYS AS (4 * side), PRIMARY KEY (id) ) @@ -692,7 +692,7 @@ eagerly fetched. * MariaDB 10.x series and onwards -* PostgreSQL as of version 12 +* PostgreSQL as of version 12 [#pgnote]_ * Oracle Database - with the caveat that RETURNING does not work correctly with UPDATE (a warning will be emitted to this effect when the UPDATE..RETURNING @@ -711,7 +711,10 @@ DDL is emitted to the database. .. seealso:: - :class:`.Computed` + :class:`.Computed` - produces a GENERATED ALWAYS AS phrase for :class:`.Column` + + .. [#pgnote] :ref:`postgresql_computed_column_notes` - notes for GENERATED ALWAYS AS + on PostgreSQL including behavioral changes as of PostgreSQL 18 .. _identity_ddl: diff --git a/lib/sqlalchemy/dialects/postgresql/base.py b/lib/sqlalchemy/dialects/postgresql/base.py index a11331a3df..804abb5817 100644 --- a/lib/sqlalchemy/dialects/postgresql/base.py +++ b/lib/sqlalchemy/dialects/postgresql/base.py @@ -1385,6 +1385,54 @@ that are subject to the action:: .. versionadded:: 2.0.40 +.. _postgresql_computed_column_notes: + +Computed Columns (GENERATED ALWAYS AS) +--------------------------------------- + +SQLAlchemy's support for the "GENERATED ALWAYS AS" SQL instruction, which +establishes a dynamic, automatically populated value for a column, is available +using the :ref:`computed_ddl` feature of SQLAlchemy DDL. E.g.:: + + from sqlalchemy import Table, Column, MetaData, Integer, Computed + + metadata_obj = MetaData() + + square = Table( + "square", + metadata_obj, + Column("id", Integer, primary_key=True), + Column("side", Integer), + Column("area", Integer, Computed("side * side")), + Column("perimeter", Integer, Computed("4 * side", persisted=True)), + ) + +There are two general varieties of the "computed" column, ``VIRTUAL`` and ``STORED``. +A ``STORED`` computed column computes and persists its value at INSERT/UPDATE time, +while a ``VIRTUAL`` computed column computes its value on access without persisting it. +This preference is indicated using the :paramref:`.Computed.persisted` parameter, +which defaults to ``None`` to use the database default behavior. + +For PostgreSQL, prior to version 18 only the ``STORED`` variant was supported, +requiring the ``STORED`` keyword to be emitted explicitly. PostgreSQL 18 added +support for ``VIRTUAL`` columns and made ``VIRTUAL`` the default behavior. + +To accommodate this change, SQLAlchemy's behavior when +:paramref:`.Computed.persisted` is not specified depends on the PostgreSQL +version: on PostgreSQL 18 and later, no keyword is rendered, allowing the +database to use its default of ``VIRTUAL``; on PostgreSQL 17 and earlier, +``STORED`` is rendered and a warning is emitted. To ensure consistent +``STORED`` behavior across all PostgreSQL versions, explicitly set +``persisted=True``. + +.. versionchanged:: 2.1 + + PostgreSQL 18+ now defaults to ``VIRTUAL`` when :paramref:`.Computed.persisted` + is not specified. A warning is emitted for older versions of PostgreSQL + when this parameter is not indicated. + + + .. _postgresql_table_valued_overview: @@ -2680,12 +2728,24 @@ class PGDDLCompiler(compiler.DDLCompiler): return "".join(table_opts) def visit_computed_column(self, generated, **kw): + if self.dialect.supports_virtual_generated_columns: + return super().visit_computed_column(generated, **kw) if generated.persisted is False: raise exc.CompileError( "PostrgreSQL computed columns do not support 'virtual' " "persistence; set the 'persisted' flag to None or True for " "PostgreSQL support." ) + elif generated.persisted is None: + util.warn( + f"Computed column {generated.column} is being created as " + "'STORED' since the current PostgreSQL version does not " + "support VIRTUAL columns. On PostgreSQL 18+, when " + "'persisted' is not " + "specified, no keyword will be rendered and VIRTUAL will be " + "used by default. Set 'persisted=True' to ensure STORED " + "behavior across all PostgreSQL versions." + ) return "GENERATED ALWAYS AS (%s) STORED" % self.sql_compiler.process( generated.sqltext, include_table=False, literal_binds=True @@ -3219,6 +3279,7 @@ class PGDialect(default.DefaultDialect): supports_native_boolean = True supports_native_uuid = True supports_smallserial = True + supports_virtual_generated_columns = True supports_sequences = True sequences_optional = True @@ -3360,6 +3421,10 @@ class PGDialect(default.DefaultDialect): self._supports_jsonb_subscripting = self.server_version_info >= (14,) + self.supports_virtual_generated_columns = self.server_version_info >= ( + 18, + ) + def get_isolation_level_values(self, dbapi_conn): # note the generic dialect doesn't have AUTOCOMMIT, however # all postgresql dialects should include AUTOCOMMIT. @@ -4156,8 +4221,7 @@ class PGDialect(default.DefaultDialect): # If a zero byte or blank string depending on driver (is also # absent for older PG versions), then not a generated column. - # Otherwise, s = stored. (Other values might be added in the - # future.) + # Otherwise, s = stored, v = virtual. if generated not in (None, "", b"\x00"): computed = dict( sqltext=default, persisted=generated in ("s", b"s") diff --git a/test/dialect/postgresql/test_compiler.py b/test/dialect/postgresql/test_compiler.py index f91453c3f4..a4c506759c 100644 --- a/test/dialect/postgresql/test_compiler.py +++ b/test/dialect/postgresql/test_compiler.py @@ -2477,9 +2477,10 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): ) @testing.combinations( - ("no_persisted", " STORED", "ignore"), - ("persisted_none", " STORED", None), + ("no_persisted", "", "ignore"), + ("persisted_none", "", None), ("persisted_true", " STORED", True), + ("persisted_false", " VIRTUAL", False), id_="iaa", ) def test_column_computed(self, text, persisted): @@ -2497,7 +2498,7 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "ALWAYS AS (x + 2)%s)" % text, ) - def test_column_computed_persisted_false(self): + def test_column_computed_persisted_false_old_version(self): m = MetaData() t = Table( "t", @@ -2505,12 +2506,34 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): Column("x", Integer), Column("y", Integer, Computed("x + 2", persisted=False)), ) - assert_raises_message( + old_dialect = postgresql.dialect() + old_dialect.supports_virtual_generated_columns = False + with expect_raises_message( exc.CompileError, "PostrgreSQL computed columns do not support 'virtual'", - schema.CreateTable(t).compile, - dialect=postgresql.dialect(), + ): + schema.CreateTable(t).compile(dialect=old_dialect) + + def test_column_computed_persisted_none_warning_old_version(self): + m = MetaData() + t = Table( + "t", + m, + Column("x", Integer), + Column("y", Integer, Computed("x + 2")), ) + old_dialect = postgresql.dialect() + old_dialect.supports_virtual_generated_columns = False + + with expect_warnings( + "Computed column t.y is being created as 'STORED' since" + ): + self.assert_compile( + schema.CreateTable(t), + "CREATE TABLE t (x INTEGER, y INTEGER GENERATED " + "ALWAYS AS (x + 2) STORED)", + dialect=old_dialect, + ) @testing.combinations(True, False) def test_column_identity(self, pk): diff --git a/test/orm/dml/test_bulk_statements.py b/test/orm/dml/test_bulk_statements.py index fcc908377b..f8153c9edd 100644 --- a/test/orm/dml/test_bulk_statements.py +++ b/test/orm/dml/test_bulk_statements.py @@ -699,11 +699,7 @@ class UpdateStmtTest(testing.AssertsExecutionResults, fixtures.TestBase): ("computed", testing.requires.computed_columns), ], ) - def test_bulk_update_onupdates( - self, - decl_base, - use_onupdate, - ): + def test_bulk_update_onupdates(self, decl_base, use_onupdate): """assert that for now, bulk ORM update by primary key does not expire or refresh onupdates.""" diff --git a/test/requirements.py b/test/requirements.py index 3b5ea9e43d..9da31c9e7d 100644 --- a/test/requirements.py +++ b/test/requirements.py @@ -15,6 +15,7 @@ from sqlalchemy.testing.exclusions import only_on from sqlalchemy.testing.exclusions import skip_if from sqlalchemy.testing.exclusions import SpecPredicate from sqlalchemy.testing.exclusions import succeeds_if +from sqlalchemy.testing.exclusions import warns_if from sqlalchemy.testing.requirements import SuiteRequirements @@ -1993,7 +1994,15 @@ class DefaultRequirements(SuiteRequirements): @property def computed_columns(self): - return skip_if(["postgresql < 12", "sqlite < 3.31", "mysql < 5.7"]) + return ( + skip_if("postgresql < 12") + + warns_if( + "postgresql < 18", + r".*PostgreSQL version does not support VIRTUAL", + assert_=False, + ) + + skip_if(["sqlite < 3.31", "mysql < 5.7"]) + ) @property def python_profiling_backend(self): @@ -2005,11 +2014,11 @@ class DefaultRequirements(SuiteRequirements): @property def computed_columns_virtual(self): - return self.computed_columns + skip_if(["postgresql"]) + return self.computed_columns + skip_if(["postgresql<18"]) @property def computed_columns_default_persisted(self): - return self.computed_columns + only_if("postgresql") + return self.computed_columns + only_if("postgresql<18") @property def computed_columns_reflect_persisted(self):