From: Mike Bayer Date: Mon, 16 Nov 2020 19:57:36 +0000 (-0500) Subject: improve cross-linking between Core /ORM for schema arg X-Git-Tag: rel_1_4_0b2~129^2 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=0c8c7b6656ccec25dff7be03f82d873b6a09c3ec;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git improve cross-linking between Core /ORM for schema arg this should be backported to 1.3 as well to as much a degree as possible. Includes a new recipe to set the default schema name on connect. this will only work on 1.4, but also requires that we fix #5708 for it to work fully. Change-Id: I882edd5bbe06ee5b4d0a9c148854a57b2bcd4741 --- diff --git a/doc/build/core/connections.rst b/doc/build/core/connections.rst index 3867c62058..aeefd27407 100644 --- a/doc/build/core/connections.rst +++ b/doc/build/core/connections.rst @@ -478,6 +478,7 @@ reverted when a connection is returned to the connection pool. :ref:`faq_execute_retry_autocommit` - a recipe that uses DBAPI autocommit to transparently reconnect to the database for read-only operations + .. _engine_stream_results: Using Server Side Cursors (a.k.a. stream results) diff --git a/doc/build/core/metadata.rst b/doc/build/core/metadata.rst index 22bad55372..8f869c91c8 100644 --- a/doc/build/core/metadata.rst +++ b/doc/build/core/metadata.rst @@ -230,8 +230,8 @@ To enable the "check first for the table existing" logic, add the .. _schema_migrations: -Altering Schemas through Migrations ------------------------------------ +Altering Database Objects through Migrations +--------------------------------------------- While SQLAlchemy directly supports emitting CREATE and DROP statements for schema constructs, the ability to alter those constructs, usually via the ALTER @@ -252,34 +252,244 @@ Alembic supersedes the `SQLAlchemy-Migrate `_ project, which is the original migration tool for SQLAlchemy and is now considered legacy. +.. _schema_table_schema_name: Specifying the Schema Name -------------------------- -Some databases support the concept of multiple schemas. A -:class:`~sqlalchemy.schema.Table` can reference this by specifying the -``schema`` keyword argument:: +Most databases support the concept of multiple "schemas" - namespaces that +refer to alternate sets of tables and other constructs. The server-side +geometry of a "schema" takes many forms, including names of "schemas" under the +scope of a particular database (e.g. PostgreSQL schemas), named sibling +databases (e.g. MySQL / MariaDB access to other databases on the same server), +as well as other concepts like tables owned by other usernames (Oracle, SQL +Server) or even names that refer to alternate database files (SQLite ATTACH) or +remote servers (Oracle DBLINK with synonyms). + +What all of the above approaches have (mostly) in common is that there's a way +of referring to this alternate set of tables using a string name. SQLAlchemy +refers to this name as the **schema name**. Within SQLAlchemy, this is nothing more than +a string name which is associated with a :class:`_schema.Table` object, and +is then rendered into SQL statements in a manner appropriate to the target +database such that the table is referred towards in its remote "schema", whatever +mechanism that is on the target database. + +The "schema" name may be associated directly with a :class:`_schema.Table` +using the :paramref:`_schema.Table.schema` argument; when using the ORM +with :ref:`declarative table ` configuration, +the parameter is passed using the ``__table_args__`` parameter dictionary. + +The "schema" name may also be associated with the :class:`_schema.MetaData` +object where it will take effect automatically for all :class:`_schema.Table` +objects associated with that :class:`_schema.MetaData` that don't otherwise +specify their own name. Finally, SQLAlchemy also supports a "dynamic" schema name +system that is often used for multi-tenant applications such that a single set +of :class:`_schema.Table` metadata may refer to a dynamically configured set of +schema names on a per-connection or per-statement basis. + +.. seealso:: + + :ref:`orm_declarative_table_schema_name` - schema name specification when using the ORM + :ref:`declarative table ` configuration + + +The most basic example is that of the :paramref:`_schema.Table.schema` argument +using a Core :class:`_schema.Table` object as follows:: - financial_info = Table('financial_info', meta, + metadata = MetaData() + + financial_info = Table( + 'financial_info', + metadata, Column('id', Integer, primary_key=True), Column('value', String(100), nullable=False), schema='remote_banks' ) -Within the :class:`~sqlalchemy.schema.MetaData` collection, this table will be -identified by the combination of ``financial_info`` and ``remote_banks``. If -another table called ``financial_info`` is referenced without the -``remote_banks`` schema, it will refer to a different -:class:`~sqlalchemy.schema.Table`. :class:`~sqlalchemy.schema.ForeignKey` -objects can specify references to columns in this table using the form -``remote_banks.financial_info.id``. +SQL that is rendered using this :class:`_schema.Table`, such as the SELECT +statement below, will explicitly qualify the table name ``financial_info`` with +the ``remote_banks`` schema name:: + + >>> print(select(financial_info)) + SELECT remote_banks.financial_info.id, remote_banks.financial_info.value + FROM remote_banks.financial_info + +When a :class:`_schema.Table` object is declared with an explicit schema +name, it is stored in the internal :class:`_schema.MetaData` namespace +using the combination of the schema and table name. We can view this +in the :attr:`_schema.MetaData.tables` collection by searching for the +key ``'remote_banks.financial_info'``:: + + >>> metadata.tables['remote_banks.financial_info'] + Table('financial_info', MetaData(), + Column('id', Integer(), table=, primary_key=True, nullable=False), + Column('value', String(length=100), table=, nullable=False), + schema='remote_banks') + +This dotted name is also what must be used when referring to the table +for use with the :class:`_schema.ForeignKey` or :class:`_schema.ForeignKeyConstraint` +objects, even if the referring table is also in that same schema:: + + customer = Table( + "customer", + metadata, + Column('id', Integer, primary_key=True), + Column('financial_info_id', ForeignKey("remote_banks.financial_info.id")), + schema='remote_banks' + ) -The ``schema`` argument should be used for any name qualifiers required, -including Oracle's "owner" attribute and similar. It also can accommodate a -dotted name for longer schemes:: +The :paramref:`_schema.Table.schema` argument may also be used with certain +dialects to indicate +a multiple-token (e.g. dotted) path to a particular table. This is particularly +important on a database such as Microsoft SQL Server where there are often +dotted "database/owner" tokens. The tokens may be placed directly in the name +at once, such as:: schema="dbo.scott" +.. seealso:: + + :ref:`multipart_schema_names` - describes use of dotted schema names + with the SQL Server dialect. + + +.. _schema_metadata_schema_name: + +Specifying a Default Schema Name with MetaData +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +The :class:`_schema.MetaData` object may also set up an explicit default +option for all :paramref:`_schema.Table.schema` parameters by passing the +:paramref:`_schema.MetaData.schema` argument to the top level :class:`_schema.MetaData` +construct:: + + metadata = MetaData(schema="remote_banks") + + financial_info = Table( + 'financial_info', + metadata, + Column('id', Integer, primary_key=True), + Column('value', String(100), nullable=False), + ) + +Above, for any :class:`_schema.Table` object (or :class:`_schema.Sequence` object +directly associated with the :class:`_schema.MetaData`) which leaves the +:paramref:`_schema.Table.schema` parameter at its default of ``None`` will instead +act as though the parameter were set to the value ``"remote_banks"``. This +includes that the :class:`_schema.Table` is cataloged in the :class:`_schema.MetaData` +using the schema-qualified name, that is:: + + metadata.tables['remote_banks.financial_info'] + +When using the :class:`_schema.ForeignKey` or :class:`_schema.ForeignKeyConstraint` +objects to refer to this table, either the schema-qualified name or the +non-schema-qualified name may be used to refer to the ``remote_banks.financial_info`` +table:: + + # either will work: + + refers_to_financial_info = Table( + 'refers_to_financial_info', + metadata, + Column('id', Integer, primary_key=True), + Column('fiid', ForeignKey('financial_info.id')), + ) + + + # or + + refers_to_financial_info = Table( + 'refers_to_financial_info', + metadata, + Column('id', Integer, primary_key=True), + Column('fiid', ForeignKey('remote_banks.financial_info.id')), + ) + +When using a :class:`_schema.MetaData` object that sets +:paramref:`_schema.MetaData.schema`, a :class:`_schema.Table` that wishes +to specify that it should not be schema qualified may use the special symbol +:data:`_schema.BLANK_SCHEMA`:: + + from sqlalchemy import BLANK_SCHEMA + + metadata = MetaData(schema="remote_banks") + + financial_info = Table( + 'financial_info', + metadata, + Column('id', Integer, primary_key=True), + Column('value', String(100), nullable=False), + schema=BLANK_SCHEMA # will not use "remote_banks" + ) + + +.. seealso:: + + :paramref:`_schema.MetaData.schema` + +.. _schema_dynamic_naming_convention: + +Applying Dynamic Schema Naming Conventions +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +The names used by the :paramref:`_schema.Table.schema` parameter may also be +applied against a lookup that is dynamic on a per-connection or per-execution +basis, so that for example in multi-tenant situations, each transaction +or statement may be targeted at a specific set of schema names that change. +The section :ref:`schema_translating` describes how this feature is used. + + +.. seealso:: + + :ref:`schema_translating` + +.. _schema_set_default_connections: + +Setting a Default Schema for New Connections +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +The above approaches all refer to methods of including an explicit schema-name +within SQL statements. Database connections in fact feature the concept +of a "default" schema, which is the name of the "schema" (or database, owner, +etc.) that takes place if a table name is not explicitly schema-qualified. +These names are usually configured at the login level, such as when connecting +to a PostgreSQL database, the default "schema" is called "public". + +There are often cases where the default "schema" cannot be set via the login +itself and instead would usefully be configured each time a connection +is made, using a statement such as "SET SEARCH_PATH" on PostgreSQL or +"ALTER SESSION" on Oracle. These approaches may be achieved by using +the :meth:`_pool.PoolEvents.connect` event, which allows access to the +DBAPI connection when it is first created. For example, to set the +Oracle CURRENT_SCHEMA variable to an alternate name:: + + from sqlalchemy import event + from sqlalchemy import create_engine + + engine = create_engine("oracle+cx_oracle://scott:tiger@tsn_name") + + @event.listens_for(engine, "connect", insert=True) + def set_current_schema(dbapi_connection, connection_record): + cursor = dbapi_connection.cursor() + cursor.execute("ALTER SESSION SET CURRENT_SCHEMA=%s" % schema_name) + cursor.close() + +Above, the ``set_current_schema()`` event handler will take place immediately +when the above :class:`_engine.Engine` first connects; as the event is +"inserted" into the beginning of the handler list, it will also take place +before the dialect's own event handlers are run, in particular including the +one that will determine the "default schema" for the connection. + +For other databases, consult the database and/or dialect documentation +for specific information regarding how default schemas are configured. + +.. versionchanged:: 1.4.0b2 The above recipe now works without the need to + establish additional event handlers. + +.. seealso:: + + :ref:`postgresql_alternate_search_path` - in the :ref:`postgresql_toplevel` dialect documentation. + Backend-Specific Options ------------------------ diff --git a/doc/build/orm/declarative_tables.rst b/doc/build/orm/declarative_tables.rst index 2aff8bbc2d..b3309b7183 100644 --- a/doc/build/orm/declarative_tables.rst +++ b/doc/build/orm/declarative_tables.rst @@ -143,6 +143,44 @@ as well as the ``__tablename__`` attribute, in a dynamic style using the :func:`_orm.declared_attr` method decorator. See the section :ref:`declarative_mixins` for examples on how this is often used. +.. _orm_declarative_table_schema_name: + +Explicit Schema Name with Declarative Table +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +The schema name for a :class:`_schema.Table` as documented at +:ref:`schema_table_schema_name` is applied to an individual :class:`_schema.Table` +using the :paramref:`_schema.Table.schema` argument. When using Declarative +tables, this option is passed like any other to the ``__table_args__`` +dictionary:: + + + class MyClass(Base): + __tablename__ = 'sometable' + __table_args__ = {'schema': 'some_schema'} + + +The schema name can also be applied to all :class:`_schema.Table` objects +globally by using the :paramref:`_schema.MetaData.schema` parameter documented +at :ref:`schema_metadata_schema_name`. The :class:`_schema.MetaData` object +may be constructed separately and passed either to :func:`_orm.registry` +or :func:`_orm.declarative_base`:: + + from sqlalchemy import metadata + metadata = MetaData(schema="some_schema") + + Base = declarative_base(metadata = metadata) + + + class MyClass(Base): + # will use "some_schema" by default + __tablename__ = 'sometable' + + +.. seealso:: + + :ref:`schema_table_schema_name` - in the :ref:`metadata_toplevel` documentation. + .. _orm_declarative_table_adding_columns: Adding New Columns diff --git a/doc/build/tutorial/metadata.rst b/doc/build/tutorial/metadata.rst index 969536c016..365e996857 100644 --- a/doc/build/tutorial/metadata.rst +++ b/doc/build/tutorial/metadata.rst @@ -358,6 +358,11 @@ objects can usually be declared without an explicit "name" field inside the constructor, as the Declarative process will name them automatically based on the attribute name that was used. +.. seealso:: + + :ref:`orm_declarative_mapping` - overview of Declarative class mapping + + Other Mapped Class Details ^^^^^^^^^^^^^^^^^^^^^^^^^^^ diff --git a/lib/sqlalchemy/dialects/postgresql/base.py b/lib/sqlalchemy/dialects/postgresql/base.py index 3c33d9ee8e..79839ae393 100644 --- a/lib/sqlalchemy/dialects/postgresql/base.py +++ b/lib/sqlalchemy/dialects/postgresql/base.py @@ -225,6 +225,46 @@ SERIALIZABLE isolation. .. versionadded:: 1.4 added support for the ``postgresql_readonly`` and ``postgresql_deferrable`` execution options. +.. _postgresql_alternate_search_path: + +Setting Alternate Search Paths on Connect +------------------------------------------ + +The PostgreSQL ``search_path`` variable refers to the list of schema names +that will be implicitly referred towards when a particular table or other +object is referenced in a SQL statement. As detailed in the next section +:ref:`postgresql_schema_reflection`, SQLAlchemy is generally organized around +the concept of keeping this variable at its default value of ``public``, +however, in order to have it set to any arbirary name or names when connections +are used automatically, the "SET SESSION search_path" command may be invoked +for all connections in a pool using the following event handler, as discussed +at :ref:`schema_set_default_connections`:: + + from sqlalchemy import event + from sqlalchemy import create_engine + + engine = create_engine("postgresql+psycopg2://scott:tiger@host/dbname") + + @event.listens_for(engine, "connect", insert=True) + def set_search_path(dbapi_connection, connection_record): + existing_autocommit = dbapi_connection.autocommit + dbapi_connection.autocommit = True + cursor = dbapi_connection.cursor() + cursor.execute("SET SESSION search_path='%s'" % schema_name) + cursor.close() + dbapi_connection.autocommit = existing_autocommit + +The reason the recipe is complicated by use of the ``.autocommit`` DBAPI +attribute is so that when the ``SET SESSION search_path`` directive is invoked, +it is invoked outside of the scope of any tranasction and therefore will not +be reverted when the DBAPI connection has a rollback. + +.. seealso:: + + :ref:`schema_set_default_connections` - in the :ref:`metadata_toplevel` documentation + + + .. _postgresql_schema_reflection: diff --git a/lib/sqlalchemy/sql/schema.py b/lib/sqlalchemy/sql/schema.py index b7e5dac313..4b19ff02a1 100644 --- a/lib/sqlalchemy/sql/schema.py +++ b/lib/sqlalchemy/sql/schema.py @@ -3982,49 +3982,11 @@ class MetaData(SchemaItem): :class:`.Sequence`, and potentially other objects associated with this :class:`_schema.MetaData`. Defaults to ``None``. - When this value is set, any :class:`_schema.Table` or - :class:`.Sequence` - which specifies ``None`` for the schema parameter will instead - have this schema name defined. To build a :class:`_schema.Table` - or :class:`.Sequence` that still has ``None`` for the schema - even when this parameter is present, use the :attr:`.BLANK_SCHEMA` - symbol. - - .. note:: - - As referred above, the :paramref:`_schema.MetaData.schema` - parameter - only refers to the **default value** that will be applied to - the :paramref:`_schema.Table.schema` parameter of an incoming - :class:`_schema.Table` object. It does not refer to how the - :class:`_schema.Table` is catalogued within the - :class:`_schema.MetaData`, - which remains consistent vs. a :class:`_schema.MetaData` - collection - that does not define this parameter. The - :class:`_schema.Table` - within the :class:`_schema.MetaData` - will still be keyed based on its - schema-qualified name, e.g. - ``my_metadata.tables["some_schema.my_table"]``. - - The current behavior of the :class:`_schema.ForeignKey` - object is to - circumvent this restriction, where it can locate a table given - the table name alone, where the schema will be assumed to be - present from this value as specified on the owning - :class:`_schema.MetaData` collection. However, - this implies that a - table qualified with BLANK_SCHEMA cannot currently be referred - to by string name from :class:`_schema.ForeignKey`. - Other parts of - SQLAlchemy such as Declarative may not have similar behaviors - built in, however may do so in a future release, along with a - consistent method of referring to a table in BLANK_SCHEMA. - - .. seealso:: + :ref:`schema_metadata_schema_name` - details on how the + :paramref:`_schema.MetaData.schema` parameter is used. + :paramref:`_schema.Table.schema` :paramref:`.Sequence.schema`