--- /dev/null
+.. change::
+ :tags: postgresql, feature
+ :tickets: 10909
+
+ Support for storage parameters in ``CREATE TABLE`` using the ``WITH``
+ clause has been added. The ``postgresql_with`` dialect option of
+ :class:`_schema.Table` accepts a mapping of key/value options.
+
+ .. seealso::
+
+ :ref:`postgresql_table_options_with` - in the PostgreSQL dialect
+ documentation
+
+.. change::
+ :tags: postgresql, usecase
+ :tickets: 10909
+
+ The PostgreSQL dialect now support reflection of table options, including
+ the storage parameters, table access method and table spaces. These options
+ are automatically reflected when autoloading a table, and are also
+ available via the :meth:`_engine.Inspector.get_table_options` and
+ :meth:`_engine.Inspector.get_multi_table_optionsmethod` methods.
------------------------
Several options for CREATE TABLE are supported directly by the PostgreSQL
-dialect in conjunction with the :class:`_schema.Table` construct, listed in
-the following sections.
+dialect in conjunction with the :class:`_schema.Table` construct, detailed
+in the following sections.
.. seealso::
.. versionadded:: 2.0.26
+.. _postgresql_table_options_with:
+
+``WITH``
+^^^^^^^^
+
+::
+
+ Table("some_table", metadata, ..., postgresql_with={"fillfactor": 100})
+
+The ``postgresql_with`` parameter accepts a dictionary of storage parameters
+that will be applied to the table using the ``WITH`` clause in the
+``CREATE TABLE`` statement. Storage parameters control various aspects of
+table behavior such as the fill factor for pages, autovacuum settings, and
+toast table parameters.
+
+When the table is created, the parameters are rendered as a comma-separated
+list within the ``WITH`` clause. For example::
+
+ Table(
+ "mytable",
+ metadata,
+ Column("id", Integer, primary_key=True),
+ postgresql_with={
+ "fillfactor": 70,
+ "autovacuum_enabled": "false",
+ "toast.vacuum_truncate": True,
+ },
+ )
+
+This will generate DDL similar to:
+
+.. sourcecode:: sql
+
+ CREATE TABLE mytable (
+ id INTEGER NOT NULL,
+ PRIMARY KEY (id)
+ ) WITH (fillfactor = 70, autovacuum_enabled = false, toast.vacuum_truncate = True)
+
+The values in the dictionary can be integers, strings, or boolean values.
+Parameter names can include dots to specify parameters for associated objects
+like toast tables (e.g., ``toast.vacuum_truncate``).
+
+.. seealso::
+
+ `PostgreSQL Storage Parameters
+ <https://www.postgresql.org/docs/current/sql-createtable.html#SQL-CREATETABLE-STORAGE-PARAMETERS>`_ -
+ documentation on available storage parameters.
+
+.. versionadded:: 2.1
+
``WITH OIDS``
^^^^^^^^^^^^^
Table("some_table", metadata, ..., postgresql_with_oids=True)
+.. note:: Support for tables "with OIDs" was removed in postgresql 12.
+
``WITHOUT OIDS``
^^^^^^^^^^^^^^^^
if pg_opts["using"]:
table_opts.append("\n USING %s" % pg_opts["using"])
+ if pg_opts["with"]:
+ storage_params = (f"{k} = {v}" for k, v in pg_opts["with"].items())
+ table_opts.append(f" WITH ({', '.join(storage_params)})")
+
if pg_opts["with_oids"] is True:
table_opts.append("\n WITH OIDS")
elif pg_opts["with_oids"] is False:
"tablespace": None,
"partition_by": None,
"with_oids": None,
+ "with": None,
"on_commit": None,
"inherits": None,
"using": None,
relkinds += pg_catalog.RELKINDS_MAT_VIEW
return relkinds
+ @reflection.cache
+ def get_table_options(self, connection, table_name, schema=None, **kw):
+ data = self.get_multi_table_options(
+ connection,
+ schema=schema,
+ filter_names=[table_name],
+ scope=ObjectScope.ANY,
+ kind=ObjectKind.ANY,
+ **kw,
+ )
+ return self._value_or_raise(data, table_name, schema)
+
+ @lru_cache()
+ def _table_options_query(self, schema, has_filter_names, scope, kind):
+ inherits_sq = (
+ select(
+ pg_catalog.pg_inherits.c.inhrelid,
+ sql.func.array_agg(
+ aggregate_order_by(
+ pg_catalog.pg_class.c.relname,
+ pg_catalog.pg_inherits.c.inhseqno,
+ )
+ ).label("parent_table_names"),
+ )
+ .select_from(pg_catalog.pg_inherits)
+ .join(
+ pg_catalog.pg_class,
+ pg_catalog.pg_inherits.c.inhparent
+ == pg_catalog.pg_class.c.oid,
+ )
+ .group_by(pg_catalog.pg_inherits.c.inhrelid)
+ .subquery("inherits")
+ )
+
+ if self.server_version_info < (12,):
+ # this is not in the pg_catalog.pg_class since it was
+ # removed in PostgreSQL version 12
+ has_oids = sql.column("relhasoids", BOOLEAN)
+ else:
+ has_oids = sql.null().label("relhasoids")
+
+ relkinds = self._kind_to_relkinds(kind)
+ query = (
+ select(
+ pg_catalog.pg_class.c.oid,
+ pg_catalog.pg_class.c.relname,
+ pg_catalog.pg_class.c.reloptions,
+ has_oids,
+ sql.case(
+ (
+ sql.and_(
+ pg_catalog.pg_am.c.amname.is_not(None),
+ pg_catalog.pg_am.c.amname
+ != sql.func.current_setting(
+ "default_table_access_method"
+ ),
+ ),
+ pg_catalog.pg_am.c.amname,
+ ),
+ else_=sql.null(),
+ ).label("access_method_name"),
+ pg_catalog.pg_tablespace.c.spcname.label("tablespace_name"),
+ inherits_sq.c.parent_table_names,
+ )
+ .select_from(pg_catalog.pg_class)
+ .outerjoin(
+ # NOTE: on postgresql < 12, this could be avoided
+ # since relam is always 0 so nothing is joined.
+ pg_catalog.pg_am,
+ pg_catalog.pg_class.c.relam == pg_catalog.pg_am.c.oid,
+ )
+ .outerjoin(
+ inherits_sq,
+ pg_catalog.pg_class.c.oid == inherits_sq.c.inhrelid,
+ )
+ .outerjoin(
+ pg_catalog.pg_tablespace,
+ pg_catalog.pg_tablespace.c.oid
+ == pg_catalog.pg_class.c.reltablespace,
+ )
+ .where(self._pg_class_relkind_condition(relkinds))
+ )
+ query = self._pg_class_filter_scope_schema(query, schema, scope=scope)
+ if has_filter_names:
+ query = query.where(
+ pg_catalog.pg_class.c.relname.in_(bindparam("filter_names"))
+ )
+ return query
+
+ def get_multi_table_options(
+ self, connection, schema, filter_names, scope, kind, **kw
+ ):
+ has_filter_names, params = self._prepare_filter_names(filter_names)
+ query = self._table_options_query(
+ schema, has_filter_names, scope, kind
+ )
+ rows = connection.execute(query, params).mappings()
+ table_options = {}
+
+ for row in rows:
+ current: dict[str, Any] = {}
+ if row["access_method_name"] is not None:
+ current["postgresql_using"] = row["access_method_name"]
+
+ if row["parent_table_names"]:
+ current["postgresql_inherits"] = tuple(
+ row["parent_table_names"]
+ )
+
+ if row["reloptions"]:
+ current["postgresql_with"] = dict(
+ option.split("=", 1) for option in row["reloptions"]
+ )
+
+ if row["relhasoids"]:
+ current["postgresql_with_oids"] = True
+
+ if row["tablespace_name"] is not None:
+ current["postgresql_tablespace"] = row["tablespace_name"]
+
+ table_options[(schema, row["relname"])] = current
+
+ return table_options.items()
+
@reflection.cache
def get_columns(self, connection, table_name, schema=None, **kw):
data = self.get_multi_columns(
Column("opcdefault", Boolean),
Column("opckeytype", OID),
)
+
+pg_inherits = Table(
+ "pg_inherits",
+ pg_catalog_meta,
+ Column("inhrelid", OID),
+ Column("inhparent", OID),
+ Column("inhseqno", Integer),
+ Column("inhdetachpending", Boolean, info={"server_version": (14,)}),
+)
+
+pg_tablespace = Table(
+ "pg_tablespace",
+ pg_catalog_meta,
+ Column("oid", OID),
+ Column("spcname", NAME),
+ Column("spcowner", OID),
+ Column("spcoptions", ARRAY(Text)),
+)
"CREATE TABLE anothertable (id INTEGER) WITHOUT OIDS",
)
+ def test_create_table_with_storage_parameters(self):
+ m = MetaData()
+
+ tbl = Table("atable1", m, postgresql_with={"fillfactor": 100})
+
+ self.assert_compile(
+ schema.CreateTable(tbl),
+ "CREATE TABLE atable1 () WITH (fillfactor = 100)",
+ )
+
+ tbl2 = Table(
+ "atable2",
+ m,
+ postgresql_with={"toast.autovacuum_insert_scale_factor": 1.25},
+ )
+
+ self.assert_compile(
+ schema.CreateTable(tbl2),
+ "CREATE TABLE atable2 () "
+ "WITH (toast.autovacuum_insert_scale_factor = 1.25)",
+ )
+
+ tbl3 = Table(
+ "atable3",
+ m,
+ postgresql_with={
+ "user_catalog_table": False,
+ "parallel_workers": 15,
+ },
+ )
+
+ self.assert_compile(
+ schema.CreateTable(tbl3),
+ "CREATE TABLE atable3 () "
+ "WITH (user_catalog_table = False, parallel_workers = 15)",
+ )
+
def test_create_table_with_oncommit_option(self):
m = MetaData()
tbl = Table(
is_true(len(rows) > 0)
for row in rows:
self.check_int_list(row, "conkey")
+
+
+class TestTableOptionsReflection(fixtures.TestBase):
+ __only_on__ = "postgresql"
+ __backend__ = True
+
+ def test_table_inherits(self, metadata, connection):
+ def assert_inherits_from(table_name, expect_base_tables):
+ table_options = inspect(connection).get_table_options(table_name)
+ eq_(
+ table_options.get("postgresql_inherits", ()),
+ expect_base_tables,
+ )
+
+ def assert_column_names(table_name, expect_columns):
+ columns = inspect(connection).get_columns(table_name)
+ eq_([c["name"] for c in columns], expect_columns)
+
+ Table("base", metadata, Column("id", INTEGER, primary_key=True))
+ Table("name_mixin", metadata, Column("name", String(16)))
+ Table("single_inherits", metadata, postgresql_inherits="base")
+ Table(
+ "single_inherits_tuple_arg",
+ metadata,
+ postgresql_inherits=("base",),
+ )
+ Table(
+ "inherits_mixin",
+ metadata,
+ postgresql_inherits=("base", "name_mixin"),
+ )
+
+ metadata.create_all(connection)
+
+ assert_inherits_from("base", ())
+ assert_inherits_from("name_mixin", ())
+
+ assert_inherits_from("single_inherits", ("base",))
+ assert_column_names("single_inherits", ["id"])
+
+ assert_inherits_from("single_inherits_tuple_arg", ("base",))
+
+ assert_inherits_from("inherits_mixin", ("base", "name_mixin"))
+ assert_column_names("inherits_mixin", ["id", "name"])
+
+ def test_table_storage_params(self, metadata, connection):
+ def assert_has_storage_param(table_name, option_key, option_value):
+ table_options = inspect(connection).get_table_options(table_name)
+ storage_params = table_options["postgresql_with"]
+ assert isinstance(storage_params, dict)
+ eq_(storage_params[option_key], option_value)
+
+ Table("table_no_storage_params", metadata)
+ Table(
+ "table_with_fillfactor",
+ metadata,
+ postgresql_with={"fillfactor": 10},
+ )
+ Table(
+ "table_with_parallel_workers",
+ metadata,
+ postgresql_with={"parallel_workers": 15},
+ )
+
+ metadata.create_all(connection)
+
+ no_params_options = inspect(connection).get_table_options(
+ "table_no_storage_params"
+ )
+ assert "postgresql_with" not in no_params_options
+
+ assert_has_storage_param("table_with_fillfactor", "fillfactor", "10")
+ assert_has_storage_param(
+ "table_with_parallel_workers", "parallel_workers", "15"
+ )
+
+ def test_table_using_default(self, metadata: MetaData, connection):
+ Table("table_using_heap", metadata, postgresql_using="heap").create(
+ connection
+ )
+ options = inspect(connection).get_table_options("table_using_heap")
+ is_false("postgresql_using" in options)
+
+ def test_table_using_custom(self, metadata: MetaData, connection):
+ if not connection.exec_driver_sql(
+ "SELECT rolsuper FROM pg_roles WHERE rolname = current_user"
+ ).scalar():
+ config.skip_test("superuser required for CREATE ACCESS METHOD")
+ connection.exec_driver_sql(
+ "CREATE ACCESS METHOD myaccessmethod "
+ "TYPE TABLE "
+ "HANDLER heap_tableam_handler"
+ )
+ Table(
+ "table_using_myaccessmethod",
+ metadata,
+ postgresql_using="myaccessmethod",
+ ).create(connection)
+
+ options = inspect(connection).get_table_options(
+ "table_using_myaccessmethod"
+ )
+ eq_(options["postgresql_using"], "myaccessmethod")
@property
def reflect_table_options(self):
- return only_on(["mysql", "mariadb", "oracle"])
+ return only_on(["mysql", "mariadb", "oracle", "postgresql"])
@property
def materialized_views(self):