From: Mike Bayer Date: Tue, 19 Mar 2024 12:35:00 +0000 (-0400) Subject: add notes clarifying the role of "$user" in pg search_path X-Git-Tag: rel_1_4_53~25 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=d7ea47ddff0500f802bf6b720f756bce1cd19a30;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git add notes clarifying the role of "$user" in pg search_path references: https://github.com/sqlalchemy/alembic/discussions/1447 Change-Id: I2ef55813699f84ac7fbca6de7522f0d3d78e6029 (cherry picked from commit 58a50c06836792da201bb610ee2f0463ac1bb073) --- diff --git a/lib/sqlalchemy/dialects/postgresql/base.py b/lib/sqlalchemy/dialects/postgresql/base.py index 6b3af4bdae..c36597bbc4 100644 --- a/lib/sqlalchemy/dialects/postgresql/base.py +++ b/lib/sqlalchemy/dialects/postgresql/base.py @@ -341,7 +341,9 @@ Remote-Schema Table Introspection and PostgreSQL search_path .. admonition:: Section Best Practices Summarized keep the ``search_path`` variable set to its default of ``public``, without - any other schema names. For other schema names, name these explicitly + any other schema names. Ensure the username used to connect **does not** + match remote schemas, or ensure the ``"$user"`` token is **removed** from + ``search_path``. For other schema names, name these explicitly within :class:`_schema.Table` definitions. Alternatively, the ``postgresql_ignore_search_path`` option will cause all reflected :class:`_schema.Table` objects to have a :attr:`_schema.Table.schema` @@ -350,12 +352,63 @@ Remote-Schema Table Introspection and PostgreSQL search_path The PostgreSQL dialect can reflect tables from any schema, as outlined in :ref:`metadata_reflection_schemas`. +In all cases, the first thing SQLAlchemy does when reflecting tables is +to **determine the default schema for the current database connection**. +It does this using the PostgreSQL ``current_schema()`` +function, illustated below using a PostgreSQL client session (i.e. using +the ``psql`` tool):: + + test=> select current_schema(); + current_schema + ---------------- + public + (1 row) + +Above we see that on a plain install of PostgreSQL, the default schema name +is the name ``public``. + +However, if your database username **matches the name of a schema**, PostgreSQL's +default is to then **use that name as the default schema**. Below, we log in +using the username ``scott``. When we create a schema named ``scott``, **it +implicitly changes the default schema**:: + + test=> select current_schema(); + current_schema + ---------------- + public + (1 row) + + test=> create schema scott; + CREATE SCHEMA + test=> select current_schema(); + current_schema + ---------------- + scott + (1 row) + +The behavior of ``current_schema()`` is derived from the +`PostgreSQL search path +`_ +variable ``search_path``, which in modern PostgreSQL versions defaults to this:: + + test=> show search_path; + search_path + ----------------- + "$user", public + (1 row) + +Where above, the ``"$user"`` variable will inject the current username as the +default schema, if one exists. Otherwise, ``public`` is used. + +When a :class:`_schema.Table` object is reflected, if it is present in the +schema indicated by the ``current_schema()`` function, **the schema name assigned +to the table is the Python value ``None``**. Otherwise, the schema name +will be assigned as the name of that schema. + With regards to tables which these :class:`_schema.Table` objects refer to via foreign key constraint, a decision must be made as to how the ``.schema`` is represented in those remote tables, in the case where that -remote schema name is also a member of the current -`PostgreSQL search path -`_. +remote schema name is also a member of the current ``search_path``. By default, the PostgreSQL dialect mimics the behavior encouraged by PostgreSQL's own ``pg_get_constraintdef()`` builtin procedure. This function @@ -461,13 +514,6 @@ We will now have ``test_schema.referred`` stored as schema-qualified:: described here are only for those users who can't, or prefer not to, stay within these guidelines. -Note that **in all cases**, the "default" schema is always reflected as -``None``. The "default" schema on PostgreSQL is that which is returned by the -PostgreSQL ``current_schema()`` function. On a typical PostgreSQL -installation, this is the name ``public``. So a table that refers to another -which is in the ``public`` (i.e. default) schema will always have the -``.schema`` attribute set to ``None``. - .. seealso:: :ref:`reflection_schema_qualified_interaction` - discussion of the issue