Oracle
^^^^^^^^^^
-The Oracle dialect uses cx_oracle as the default DBAPI::
+The preferred Oracle dialect uses the python-oracledb driver as the DBAPI::
- engine = create_engine("oracle://scott:tiger@127.0.0.1:1521/sidname")
+ engine = create_engine("oracle+oracledb://scott:tiger@127.0.0.1:1521/?service_name=freepdb1")
- engine = create_engine("oracle+cx_oracle://scott:tiger@tnsname")
+ engine = create_engine("oracle+oracledb://scott:tiger@tnsalias")
+
+The Oracle dialect uses the obsolete cx_Oracle driver as the default DBAPI::
+
+ engine = create_engine("oracle://scott:tiger@127.0.0.1:1521/?service_name=freepdb1")
+
+ engine = create_engine("oracle+cx_oracle://scott:tiger@tnsalias")
More notes on connecting to Oracle at :ref:`oracle_toplevel`.
... conn.execute(text("select :some_private_name"), {"some_private_name": "pii"})
2020-10-24 12:48:32,808 INFO sqlalchemy.engine.Engine select ?
2020-10-24 12:48:32,808 INFO sqlalchemy.engine.Engine [SQL parameters hidden due to hide_parameters=True]
-
.. autoclass:: TIMESTAMP
:members: __init__
-.. _cx_oracle:
-
-cx_Oracle
----------
-
-.. automodule:: sqlalchemy.dialects.oracle.cx_oracle
-
.. _oracledb:
python-oracledb
.. automodule:: sqlalchemy.dialects.oracle.oracledb
+.. _cx_oracle:
+
+cx_Oracle
+---------
+
+.. automodule:: sqlalchemy.dialects.oracle.cx_oracle
# mypy: ignore-errors
-r"""
-.. dialect:: oracle
+r""".. dialect:: oracle
:name: Oracle
:normal_support: 11+
:best_effort: 9+
Auto Increment Behavior
-----------------------
-SQLAlchemy Table objects which include integer primary keys are usually
-assumed to have "autoincrementing" behavior, meaning they can generate their
-own primary key values upon INSERT. For use within Oracle, two options are
-available, which are the use of IDENTITY columns (Oracle 12 and above only)
-or the association of a SEQUENCE with the column.
+SQLAlchemy Table objects which include integer primary keys are usually assumed
+to have "autoincrementing" behavior, meaning they can generate their own
+primary key values upon INSERT. For use within Oracle Database, two options are
+available, which are the use of IDENTITY columns (Oracle Database 12 and above
+only) or the association of a SEQUENCE with the column.
-Specifying GENERATED AS IDENTITY (Oracle 12 and above)
-~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
+Specifying GENERATED AS IDENTITY (Oracle Database 12 and above)
+~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
-Starting from version 12 Oracle can make use of identity columns using
-the :class:`_sql.Identity` to specify the autoincrementing behavior::
+Starting from version 12, Oracle Database can make use of identity columns
+using the :class:`_sql.Identity` to specify the autoincrementing behavior::
t = Table('mytable', metadata,
Column('id', Integer, Identity(start=3), primary_key=True),
The :class:`_schema.Identity` object support many options to control the
"autoincrementing" behavior of the column, like the starting value, the
-incrementing value, etc.
-In addition to the standard options, Oracle supports setting
-:paramref:`_schema.Identity.always` to ``None`` to use the default
-generated mode, rendering GENERATED AS IDENTITY in the DDL.
-Oracle also supports two custom options specified using dialect kwargs:
+incrementing value, etc. In addition to the standard options, Oracle Database
+supports setting :paramref:`_schema.Identity.always` to ``None`` to use the
+default generated mode, rendering GENERATED AS IDENTITY in the DDL. Oracle
+Database also supports two custom options specified using dialect kwargs:
* ``oracle_on_null``: when set to ``True`` renders ``ON NULL`` in conjunction
with a 'BY DEFAULT' identity column.
identity is definitively ordered. May be necessary to provide deterministic
ordering using Oracle RAC.
-Using a SEQUENCE (all Oracle versions)
-~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
+Using a SEQUENCE (all Oracle Database versions)
+~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
-Older version of Oracle had no "autoincrement"
-feature, SQLAlchemy relies upon sequences to produce these values. With the
-older Oracle versions, *a sequence must always be explicitly specified to
-enable autoincrement*. This is divergent with the majority of documentation
-examples which assume the usage of an autoincrement-capable database. To
-specify sequences, use the sqlalchemy.schema.Sequence object which is passed
-to a Column construct::
+Older version of Oracle Database had no "autoincrement" feature: SQLAlchemy
+relies upon sequences to produce these values. With the older Oracle Database
+versions, *a sequence must always be explicitly specified to enable
+autoincrement*. This is divergent with the majority of documentation examples
+which assume the usage of an autoincrement-capable database. To specify
+sequences, use the sqlalchemy.schema.Sequence object which is passed to a
+Column construct::
t = Table('mytable', metadata,
Column('id', Integer, Sequence('id_seq', start=1), primary_key=True),
autoload_with=engine
)
-In addition to the standard options, Oracle supports the following custom
-option specified using dialect kwargs:
+In addition to the standard options, Oracle Database supports the following
+custom option specified using dialect kwargs:
* ``oracle_order``: when ``True``, renders the ORDER keyword, indicating the
sequence is definitively ordered. May be necessary to provide deterministic
- ordering using Oracle RAC.
+ ordering using Oracle Real Application Clusters (RAC).
.. versionchanged:: 1.4 Added :class:`_schema.Identity` construct
in a :class:`_schema.Column` to specify the option of an autoincrementing
Transaction Isolation Level / Autocommit
----------------------------------------
-The Oracle database supports "READ COMMITTED" and "SERIALIZABLE" modes of
-isolation. The AUTOCOMMIT isolation level is also supported by the cx_Oracle
-dialect.
+Oracle Database supports "READ COMMITTED" and "SERIALIZABLE" modes of
+isolation. The AUTOCOMMIT isolation level is also supported by the
+python-oracledb and cx_Oracle dialects.
To set using per-connection execution options::
isolation_level="AUTOCOMMIT"
)
-For ``READ COMMITTED`` and ``SERIALIZABLE``, the Oracle dialect sets the
-level at the session level using ``ALTER SESSION``, which is reverted back
-to its default setting when the connection is returned to the connection
-pool.
+For ``READ COMMITTED`` and ``SERIALIZABLE``, the Oracle dialects sets the level
+at the session level using ``ALTER SESSION``, which is reverted back to its
+default setting when the connection is returned to the connection pool.
Valid values for ``isolation_level`` include:
.. note:: The implementation for the
:meth:`_engine.Connection.get_isolation_level` method as implemented by the
- Oracle dialect necessarily forces the start of a transaction using the
- Oracle LOCAL_TRANSACTION_ID function; otherwise no level is normally
- readable.
+ Oracle dialects necessarily force the start of a transaction using the
+ Oracle Database DBMS_TRANSACTION.LOCAL_TRANSACTION_ID function; otherwise no
+ level is normally readable.
Additionally, the :meth:`_engine.Connection.get_isolation_level` method will
raise an exception if the ``v$transaction`` view is not available due to
permissions or other reasons, which is a common occurrence in Oracle
installations.
- The cx_Oracle dialect attempts to call the
+ The python-oracledb and cx_Oracle dialects attempt to call the
:meth:`_engine.Connection.get_isolation_level` method when the dialect makes
its first connection to the database in order to acquire the
"default"isolation level. This default level is necessary so that the level
can be reset on a connection after it has been temporarily modified using
- :meth:`_engine.Connection.execution_options` method. In the common event
+ :meth:`_engine.Connection.execution_options` method. In the common event
that the :meth:`_engine.Connection.get_isolation_level` method raises an
exception due to ``v$transaction`` not being readable as well as any other
database-related failure, the level is assumed to be "READ COMMITTED". No
warning is emitted for this initial first-connect condition as it is
expected to be a common restriction on Oracle databases.
-.. versionadded:: 1.3.16 added support for AUTOCOMMIT to the cx_oracle dialect
+.. versionadded:: 1.3.16 added support for AUTOCOMMIT to the cx_Oracle dialect
as well as the notion of a default isolation level
.. versionadded:: 1.3.21 Added support for SERIALIZABLE as well as live
Identifier Casing
-----------------
-In Oracle, the data dictionary represents all case insensitive identifier
-names using UPPERCASE text. SQLAlchemy on the other hand considers an
-all-lower case identifier name to be case insensitive. The Oracle dialect
-converts all case insensitive identifiers to and from those two formats during
-schema level communication, such as reflection of tables and indexes. Using
-an UPPERCASE name on the SQLAlchemy side indicates a case sensitive
-identifier, and SQLAlchemy will quote the name - this will cause mismatches
-against data dictionary data received from Oracle, so unless identifier names
-have been truly created as case sensitive (i.e. using quoted names), all
-lowercase names should be used on the SQLAlchemy side.
+In Oracle Database, the data dictionary represents all case insensitive
+identifier names using UPPERCASE text. SQLAlchemy on the other hand considers
+an all-lower case identifier name to be case insensitive. The Oracle dialects
+convert all case insensitive identifiers to and from those two formats during
+schema level communication, such as reflection of tables and indexes. Using an
+UPPERCASE name on the SQLAlchemy side indicates a case sensitive identifier,
+and SQLAlchemy will quote the name - this will cause mismatches against data
+dictionary data received from Oracle, so unless identifier names have been
+truly created as case sensitive (i.e. using quoted names), all lowercase names
+should be used on the SQLAlchemy side.
.. _oracle_max_identifier_lengths:
Max Identifier Lengths
----------------------
-Oracle has changed the default max identifier length as of Oracle Server
-version 12.2. Prior to this version, the length was 30, and for 12.2 and
-greater it is now 128. This change impacts SQLAlchemy in the area of
-generated SQL label names as well as the generation of constraint names,
-particularly in the case where the constraint naming convention feature
-described at :ref:`constraint_naming_conventions` is being used.
-
-To assist with this change and others, Oracle includes the concept of a
-"compatibility" version, which is a version number that is independent of the
-actual server version in order to assist with migration of Oracle databases,
-and may be configured within the Oracle server itself. This compatibility
-version is retrieved using the query ``SELECT value FROM v$parameter WHERE
-name = 'compatible';``. The SQLAlchemy Oracle dialect, when tasked with
+Oracle Database changed the default max identifier length as of Oracle Database
+12.2. Prior to this version, the length was 30, and for 12.2 and greater it is
+now 128. This change impacts SQLAlchemy in the area of generated SQL label
+names as well as the generation of constraint names, particularly in the case
+where the constraint naming convention feature described at
+:ref:`constraint_naming_conventions` is being used.
+
+To assist with this change and others, Oracle Database includes the concept of
+a "compatibility" version, which is a version number that is independent of the
+actual server version in order to assist with migration of databases, and may
+be configured within the Oracle Database server itself. This compatibility
+version is retrieved using the query ``SELECT value FROM v$parameter WHERE name
+= 'compatible';``. The SQLAlchemy Oracle dialects, when tasked with
determining the default max identifier length, will attempt to use this query
upon first connect in order to determine the effective compatibility version of
the server, which determines what the maximum allowed identifier length is for
-the server. If the table is not available, the server version information is
+the server. If the table is not available, the server version information is
used instead.
-As of SQLAlchemy 1.4, the default max identifier length for the Oracle dialect
-is 128 characters. Upon first connect, the compatibility version is detected
-and if it is less than Oracle version 12.2, the max identifier length is
-changed to be 30 characters. In all cases, setting the
+As of SQLAlchemy 1.4, the default max identifier length for the Oracle dialects
+is 128 characters. Upon first connection, the compatibility version is
+detected and if it is less than Oracle Database version 12.2, the max
+identifier length is changed to be 30 characters. In all cases, setting the
:paramref:`_sa.create_engine.max_identifier_length` parameter will bypass this
change and the value given will be used as is::
engine = create_engine(
- "oracle+cx_oracle://scott:tiger@oracle122",
+ "oracle+oracledb://scott:tiger@oracle122",
max_identifier_length=30)
The maximum identifier length comes into play both when generating anonymized
CREATE INDEX ix_some_column_name_1some_column_name_2some_column_name_3 ON t
(some_column_name_1, some_column_name_2, some_column_name_3)
-Applications which have run versions of SQLAlchemy prior to 1.4 on an Oracle
-server version 12.2 or greater are therefore subject to the scenario of a
+Applications which have run versions of SQLAlchemy prior to 1.4 on Oracle
+Database version 12.2 or greater are therefore subject to the scenario of a
database migration that wishes to "DROP CONSTRAINT" on a name that was
previously generated with the shorter length. This migration will fail when
the identifier length is changed without the name of the index or constraint
first being adjusted. Such applications are strongly advised to make use of
-:paramref:`_sa.create_engine.max_identifier_length`
-in order to maintain control
-of the generation of truncated names, and to fully review and test all database
-migrations in a staging environment when changing this value to ensure that the
-impact of this change has been mitigated.
+:paramref:`_sa.create_engine.max_identifier_length` in order to maintain
+control of the generation of truncated names, and to fully review and test all
+database migrations in a staging environment when changing this value to ensure
+that the impact of this change has been mitigated.
-.. versionchanged:: 1.4 the default max_identifier_length for Oracle is 128
- characters, which is adjusted down to 30 upon first connect if an older
- version of Oracle server (compatibility version < 12.2) is detected.
+.. versionchanged:: 1.4 the default max_identifier_length for Oracle Datab ase
+ is 128 characters, which is adjusted down to 30 upon first connect if an
+ older version of Oracle Database (compatibility version < 12.2) is detected.
LIMIT/OFFSET/FETCH Support
--------------------------
-Methods like :meth:`_sql.Select.limit` and :meth:`_sql.Select.offset` make
-use of ``FETCH FIRST N ROW / OFFSET N ROWS`` syntax assuming
-Oracle 12c or above, and assuming the SELECT statement is not embedded within
-a compound statement like UNION. This syntax is also available directly by using
-the :meth:`_sql.Select.fetch` method.
+Methods like :meth:`_sql.Select.limit` and :meth:`_sql.Select.offset` make use
+of ``FETCH FIRST N ROW / OFFSET N ROWS`` syntax assuming Oracle Database 12c or
+above, and assuming the SELECT statement is not embedded within a compound
+statement like UNION. This syntax is also available directly by using the
+:meth:`_sql.Select.fetch` method.
.. versionchanged:: 2.0 the Oracle dialect now uses
``FETCH FIRST N ROW / OFFSET N ROWS`` for all
behavior using window functions, specify the ``enable_offset_fetch=False``
dialect parameter to :func:`_sa.create_engine`.
-The use of ``FETCH FIRST / OFFSET`` may be disabled on any Oracle version
-by passing ``enable_offset_fetch=False`` to :func:`_sa.create_engine`, which
-will force the use of "legacy" mode that makes use of window functions.
+The use of ``FETCH FIRST / OFFSET`` may be disabled on any Oracle Database
+version by passing ``enable_offset_fetch=False`` to :func:`_sa.create_engine`,
+which will force the use of "legacy" mode that makes use of window functions.
This mode is also selected automatically when using a version of Oracle
-prior to 12c.
+Database prior to 12c.
When using legacy mode, or when a :class:`.Select` statement
with limit/offset is embedded in a compound statement, an emulated approach for
If using :meth:`_sql.Select.limit` and :meth:`_sql.Select.offset`, or with the
ORM the :meth:`_orm.Query.limit` and :meth:`_orm.Query.offset` methods on an
-Oracle version prior to 12c, the following notes apply:
+Oracle Database version prior to 12c, the following notes apply:
* SQLAlchemy currently makes use of ROWNUM to achieve
LIMIT/OFFSET; the exact methodology is taken from
RETURNING Support
-----------------
-The Oracle database supports RETURNING fully for INSERT, UPDATE and DELETE
-statements that are invoked with a single collection of bound parameters
-(that is, a ``cursor.execute()`` style statement; SQLAlchemy does not generally
+Oracle Database supports RETURNING fully for INSERT, UPDATE and DELETE
+statements that are invoked with a single collection of bound parameters (that
+is, a ``cursor.execute()`` style statement; SQLAlchemy does not generally
support RETURNING with :term:`executemany` statements). Multiple rows may be
returned as well.
-.. versionchanged:: 2.0 the Oracle backend has full support for RETURNING
- on parity with other backends.
+.. versionchanged:: 2.0 the Oracle Database backend has full support for
+ RETURNING on parity with other backends.
ON UPDATE CASCADE
-----------------
-Oracle doesn't have native ON UPDATE CASCADE functionality. A trigger based
-solution is available at
+Oracle Database doesn't have native ON UPDATE CASCADE functionality. A trigger
+based solution is available at
https://web.archive.org/web/20090317041251/https://asktom.oracle.com/tkyte/update_cascade/index.html
When using the SQLAlchemy ORM, the ORM has limited ability to manually issue
"deferrable=True, initially='deferred'" keyword arguments,
and specify "passive_updates=False" on each relationship().
-Oracle 8 Compatibility
-----------------------
+Oracle Database 8 Compatibility
+-------------------------------
-.. warning:: The status of Oracle 8 compatibility is not known for SQLAlchemy
- 2.0.
+.. warning:: The status of Oracle Database 8 compatibility is not known for
+ SQLAlchemy 2.0.
-When Oracle 8 is detected, the dialect internally configures itself to the
-following behaviors:
+When Oracle Database 8 is detected, the dialect internally configures itself to
+the following behaviors:
* the use_ansi flag is set to False. This has the effect of converting all
JOIN phrases into the WHERE clause, and in the case of LEFT OUTER JOIN
some_table = Table('some_table', autoload_with=some_engine,
oracle_resolve_synonyms=True)
-When this flag is set, the given name (such as ``some_table`` above) will
-be searched not just in the ``ALL_TABLES`` view, but also within the
+When this flag is set, the given name (such as ``some_table`` above) will be
+searched not just in the ``ALL_TABLES`` view, but also within the
``ALL_SYNONYMS`` view to see if this name is actually a synonym to another
-name. If the synonym is located and refers to a DBLINK, the oracle dialect
-knows how to locate the table's information using DBLINK syntax(e.g.
+name. If the synonym is located and refers to a DBLINK, the Oracle dialects
+know how to locate the table's information using DBLINK syntax(e.g.
``@dblink``).
``oracle_resolve_synonyms`` is accepted wherever reflection arguments are
Constraint Reflection
---------------------
-The Oracle dialect can return information about foreign key, unique, and
-CHECK constraints, as well as indexes on tables.
+The Oracle dialects can return information about foreign key, unique, and CHECK
+constraints, as well as indexes on tables.
Raw information regarding these constraints can be acquired using
:meth:`_reflection.Inspector.get_foreign_keys`,
Note the following caveats:
* When using the :meth:`_reflection.Inspector.get_check_constraints` method,
- Oracle
- builds a special "IS NOT NULL" constraint for columns that specify
- "NOT NULL". This constraint is **not** returned by default; to include
- the "IS NOT NULL" constraints, pass the flag ``include_all=True``::
+ Oracle dialects build a special "IS NOT NULL" constraint for columns that
+ specify "NOT NULL". This constraint is **not** returned by default; to
+ include the "IS NOT NULL" constraints, pass the flag ``include_all=True``::
from sqlalchemy import create_engine, inspect
:class:`.Index`
with the ``unique=True`` flag set.
-* Oracle creates an implicit index for the primary key of a table; this index
- is **excluded** from all index results.
+* Oracle Database creates an implicit index for the primary key of a table;
+ this index is **excluded** from all index results.
* the list of columns reflected for an index will not include column names
that start with SYS_NC.
# exclude SYSAUX and SOME_TABLESPACE, but not SYSTEM
e = create_engine(
- "oracle+cx_oracle://scott:tiger@xe",
+ "oracle+oracledb://scott:tiger@localhost:1521/?service_name=freepdb1",
exclude_tablespaces=["SYSAUX", "SOME_TABLESPACE"])
DateTime Compatibility
----------------------
-Oracle has no datatype known as ``DATETIME``, it instead has only ``DATE``,
-which can actually store a date and time value. For this reason, the Oracle
-dialect provides a type :class:`_oracle.DATE` which is a subclass of
-:class:`.DateTime`. This type has no special behavior, and is only
-present as a "marker" for this type; additionally, when a database column
-is reflected and the type is reported as ``DATE``, the time-supporting
-:class:`_oracle.DATE` type is used.
+Oracle Database has no datatype known as ``DATETIME``, it instead has only
+``DATE``, which can actually store a date and time value. For this reason, the
+Oracle dialects provide a type :class:`_oracle.DATE` which is a subclass of
+:class:`.DateTime`. This type has no special behavior, and is only present as
+a "marker" for this type; additionally, when a database column is reflected and
+the type is reported as ``DATE``, the time-supporting :class:`_oracle.DATE`
+type is used.
.. _oracle_table_options:
-Oracle Table Options
---------------------
+Oracle Database Table Options
+-----------------------------
-The CREATE TABLE phrase supports the following options with Oracle
-in conjunction with the :class:`_schema.Table` construct:
+The CREATE TABLE phrase supports the following options with Oracle dialects in
+conjunction with the :class:`_schema.Table` construct:
* ``ON COMMIT``::
.. _oracle_index_options:
-Oracle Specific Index Options
------------------------------
+Oracle Database Specific Index Options
+--------------------------------------
Bitmap Indexes
~~~~~~~~~~~~~~
Index compression
~~~~~~~~~~~~~~~~~
-Oracle has a more efficient storage mode for indexes containing lots of
-repeated values. Use the ``oracle_compress`` parameter to turn on key
+Oracle Database has a more efficient storage mode for indexes containing lots
+of repeated values. Use the ``oracle_compress`` parameter to turn on key
compression::
Index('my_index', my_table.c.data, oracle_compress=True)
# mypy: ignore-errors
-r"""
-.. dialect:: oracle+cx_oracle
+r""".. dialect:: oracle+cx_oracle
:name: cx-Oracle
:dbapi: cx_oracle
:connectstring: oracle+cx_oracle://user:pass@hostname:port[/dbname][?service_name=<service>[&key=value&key=value...]]
:url: https://oracle.github.io/python-cx_Oracle/
+Description
+-----------
+
+cx_Oracle was the original driver for Oracle Database. It was superseded by
+python-oracledb which should be used instead.
+
DSN vs. Hostname connections
-----------------------------
Hostname Connections with Easy Connect Syntax
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
-Given a hostname, port and service name of the target Oracle Database, for
-example from Oracle's `Easy Connect syntax
-<https://cx-oracle.readthedocs.io/en/latest/user_guide/connection_handling.html#easy-connect-syntax-for-connection-strings>`_,
-then connect in SQLAlchemy using the ``service_name`` query string parameter::
+Given a hostname, port and service name of the target database, for example
+from Oracle Database's Easy Connect syntax then connect in SQLAlchemy using the
+``service_name`` query string parameter::
- engine = create_engine("oracle+cx_oracle://scott:tiger@hostname:port/?service_name=myservice&encoding=UTF-8&nencoding=UTF-8")
+ engine = create_engine("oracle+cx_oracle://scott:tiger@hostname:port?service_name=myservice&encoding=UTF-8&nencoding=UTF-8")
-The `full Easy Connect syntax
-<https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=GUID-B0437826-43C1-49EC-A94D-B650B6A4A6EE>`_
-is not supported. Instead, use a ``tnsnames.ora`` file and connect using a
-DSN.
+Note that the default driver value for encoding and nencoding was changed to
+“UTF-8” in cx_Oracle 8.0 so these parameters can be omitted when using that
+version, or later.
-Connections with tnsnames.ora or Oracle Cloud
-^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+To use a full Easy Connect string, pass it as the ``dsn`` key value in a
+:paramref:`_sa.create_engine.connect_args` dictionary::
-Alternatively, if no port, database name, or ``service_name`` is provided, the
-dialect will use an Oracle DSN "connection string". This takes the "hostname"
-portion of the URL as the data source name. For example, if the
-``tnsnames.ora`` file contains a `Net Service Name
-<https://cx-oracle.readthedocs.io/en/latest/user_guide/connection_handling.html#net-service-names-for-connection-strings>`_
-of ``myalias`` as below::
+ import cx_Oracle
+ e = create_engine(
+ "oracle+cx_oracle://@",
+ connect_args={
+ "user": "scott",
+ "password": "tiger",
+ "dsn": "hostname:port/myservice?transport_connect_timeout=30&expire_time=60"
+ }
+ )
+
+Connections with tnsnames.ora or to Oracle Autonomous Database
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+Alternatively, if no port, database name, or service name is provided, the
+dialect will use an Oracle Database DSN "connection string". This takes the
+"hostname" portion of the URL as the data source name. For example, if the
+``tnsnames.ora`` file contains a TNS Alias of ``myalias`` as below::
myalias =
(DESCRIPTION =
hostname portion of the URL, without specifying a port, database name or
``service_name``::
- engine = create_engine("oracle+cx_oracle://scott:tiger@myalias/?encoding=UTF-8&nencoding=UTF-8")
+ engine = create_engine("oracle+cx_oracle://scott:tiger@myalias")
-Users of Oracle Cloud should use this syntax and also configure the cloud
+Users of Oracle Autonomous Database should use this syntax. If the database is
+configured for mutural TLS ("mTLS"), then you must also configure the cloud
wallet as shown in cx_Oracle documentation `Connecting to Autononmous Databases
<https://cx-oracle.readthedocs.io/en/latest/user_guide/connection_handling.html#autonomousdb>`_.
SID Connections
^^^^^^^^^^^^^^^
-To use Oracle's obsolete SID connection syntax, the SID can be passed in a
-"database name" portion of the URL as below::
+To use Oracle Database's obsolete System Identifier connection syntax, the SID
+can be passed in a "database name" portion of the URL::
- engine = create_engine("oracle+cx_oracle://scott:tiger@hostname:1521/dbname?encoding=UTF-8&nencoding=UTF-8")
+ engine = create_engine("oracle+cx_oracle://scott:tiger@hostname:port/dbname")
Above, the DSN passed to cx_Oracle is created by ``cx_Oracle.makedsn()`` as
follows::
>>> cx_Oracle.makedsn("hostname", 1521, sid="dbname")
'(DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=hostname)(PORT=1521))(CONNECT_DATA=(SID=dbname)))'
+Note that although the SQLAlchemy syntax ``hostname:port/dbname`` looks like
+Oracle's Easy Connect syntax it is different. It uses a SID in place of the
+service name required by Easy Connect. The Easy Connect syntax does not
+support SIDs.
+
Passing cx_Oracle connect arguments
-----------------------------------
-Additional connection arguments can usually be passed via the URL
-query string; particular symbols like ``cx_Oracle.SYSDBA`` are intercepted
-and converted to the correct symbol::
+Additional connection arguments can usually be passed via the URL query string;
+particular symbols like ``SYSDBA`` are intercepted and converted to the correct
+symbol::
e = create_engine(
"oracle+cx_oracle://user:pass@dsn?encoding=UTF-8&nencoding=UTF-8&mode=SYSDBA&events=true")
-.. versionchanged:: 1.3 the cx_oracle dialect now accepts all argument names
+.. versionchanged:: 1.3 the cx_Oracle dialect now accepts all argument names
within the URL string itself, to be passed to the cx_Oracle DBAPI. As
was the case earlier but not correctly documented, the
:paramref:`_sa.create_engine.connect_args` parameter also accepts all
}
)
-Note that the default value for ``encoding`` and ``nencoding`` was changed to
-"UTF-8" in cx_Oracle 8.0 so these parameters can be omitted when using that
-version, or later.
+Note that the default driver value for ``encoding`` and ``nencoding`` was
+changed to "UTF-8" in cx_Oracle 8.0 so these parameters can be omitted when
+using that version, or later.
Options consumed by the SQLAlchemy cx_Oracle dialect outside of the driver
--------------------------------------------------------------------------
to ``None``, indicating that the driver default should be used (typically
the value is 100). This setting controls how many rows are buffered when
fetching rows, and can have a significant effect on performance when
- modified. The setting is used for both ``cx_Oracle`` as well as
- ``oracledb``.
+ modified.
.. versionchanged:: 2.0.26 - changed the default value from 50 to None,
to use the default value of the driver itself.
Using cx_Oracle SessionPool
---------------------------
-The cx_Oracle library provides its own connection pool implementation that may
-be used in place of SQLAlchemy's pooling functionality. This can be achieved
-by using the :paramref:`_sa.create_engine.creator` parameter to provide a
-function that returns a new connection, along with setting
+The cx_Oracle driver provides its own connection pool implementation that may
+be used in place of SQLAlchemy's pooling functionality. The driver pool
+supports Oracle Database features such dead connection detection, connection
+draining for planned database downtime, support for Oracle Application
+Continuity and Transparent Application Continuity, and gives support for
+Database Resident Connection Pooling (DRCP).
+
+Using the driver pool can be achieved by using the
+:paramref:`_sa.create_engine.creator` parameter to provide a function that
+returns a new connection, along with setting
:paramref:`_sa.create_engine.pool_class` to ``NullPool`` to disable
SQLAlchemy's pooling::
pool = cx_Oracle.SessionPool(
user="scott", password="tiger", dsn="orclpdb",
- min=2, max=5, increment=1, threaded=True,
- encoding="UTF-8", nencoding="UTF-8"
+ min=1, max=4, increment=1, threaded=True,
+ encoding="UTF-8", nencoding="UTF-8"
)
engine = create_engine("oracle+cx_oracle://", creator=pool.acquire, poolclass=NullPool)
connection pooling::
with engine.connect() as conn:
- print(conn.scalar("select 1 FROM dual"))
-
+ print(conn.scalar("select 1 from dual"))
As well as providing a scalable solution for multi-user applications, the
cx_Oracle session pool supports some Oracle features such as DRCP and
`Application Continuity
<https://cx-oracle.readthedocs.io/en/latest/user_guide/ha.html#application-continuity-ac>`_.
+Note that the pool creation parameters ``threaded``, ``encoding`` and
+``nencoding`` were deprecated in later cx_Oracle releases.
+
Using Oracle Database Resident Connection Pooling (DRCP)
--------------------------------------------------------
-When using Oracle's `DRCP
-<https://www.oracle.com/pls/topic/lookup?ctx=dblatest&id=GUID-015CA8C1-2386-4626-855D-CC546DDC1086>`_,
-the best practice is to pass a connection class and "purity" when acquiring a
-connection from the SessionPool. Refer to the `cx_Oracle DRCP documentation
+When using Oracle Database's DRCP, the best practice is to pass a connection
+class and "purity" when acquiring a connection from the SessionPool. Refer to
+the `cx_Oracle DRCP documentation
<https://cx-oracle.readthedocs.io/en/latest/user_guide/connection_handling.html#database-resident-connection-pooling-drcp>`_.
This can be achieved by wrapping ``pool.acquire()``::
pool = cx_Oracle.SessionPool(
user="scott", password="tiger", dsn="orclpdb",
min=2, max=5, increment=1, threaded=True,
- encoding="UTF-8", nencoding="UTF-8"
+ encoding="UTF-8", nencoding="UTF-8"
)
def creator():
pooling and Oracle Database additionally uses DRCP::
with engine.connect() as conn:
- print(conn.scalar("select 1 FROM dual"))
+ print(conn.scalar("select 1 from dual"))
.. _cx_oracle_unicode:
-------
As is the case for all DBAPIs under Python 3, all strings are inherently
-Unicode strings. In all cases however, the driver requires an explicit
+Unicode strings. In all cases however, the driver requires an explicit
encoding configuration.
Ensuring the Correct Client Encoding
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
The long accepted standard for establishing client encoding for nearly all
-Oracle related software is via the `NLS_LANG <https://www.oracle.com/database/technologies/faq-nls-lang.html>`_
-environment variable. cx_Oracle like most other Oracle drivers will use
-this environment variable as the source of its encoding configuration. The
-format of this variable is idiosyncratic; a typical value would be
-``AMERICAN_AMERICA.AL32UTF8``.
+Oracle Database related software is via the `NLS_LANG
+<https://www.oracle.com/database/technologies/faq-nls-lang.html>`_ environment
+variable. Older versions of cx_Oracle use this environment variable as the
+source of its encoding configuration. The format of this variable is
+Territory_Country.CharacterSet; a typical value would be
+``AMERICAN_AMERICA.AL32UTF8``. cx_Oracle version 8 and later use the character
+set "UTF-8" by default, and ignore the character set component of NLS_LANG.
-The cx_Oracle driver also supports a programmatic alternative which is to
-pass the ``encoding`` and ``nencoding`` parameters directly to its
-``.connect()`` function. These can be present in the URL as follows::
+The cx_Oracle driver also supported a programmatic alternative which is to pass
+the ``encoding`` and ``nencoding`` parameters directly to its ``.connect()``
+function. These can be present in the URL as follows::
- engine = create_engine("oracle+cx_oracle://scott:tiger@orclpdb/?encoding=UTF-8&nencoding=UTF-8")
+ engine = create_engine("oracle+cx_oracle://scott:tiger@tnsalias?encoding=UTF-8&nencoding=UTF-8")
For the meaning of the ``encoding`` and ``nencoding`` parameters, please
consult
Unicode-specific Column datatypes
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
-The Core expression language handles unicode data by use of the :class:`.Unicode`
-and :class:`.UnicodeText`
-datatypes. These types correspond to the VARCHAR2 and CLOB Oracle datatypes by
-default. When using these datatypes with Unicode data, it is expected that
-the Oracle database is configured with a Unicode-aware character set, as well
-as that the ``NLS_LANG`` environment variable is set appropriately, so that
-the VARCHAR2 and CLOB datatypes can accommodate the data.
+The Core expression language handles unicode data by use of the
+:class:`.Unicode` and :class:`.UnicodeText` datatypes. These types correspond
+to the VARCHAR2 and CLOB Oracle Database datatypes by default. When using
+these datatypes with Unicode data, it is expected that the database is
+configured with a Unicode-aware character set, as well as that the ``NLS_LANG``
+environment variable is set appropriately (this applies to older versions of
+cx_Oracle), so that the VARCHAR2 and CLOB datatypes can accommodate the data.
-In the case that the Oracle database is not configured with a Unicode character
+In the case that Oracle Database is not configured with a Unicode character
set, the two options are to use the :class:`_types.NCHAR` and
:class:`_oracle.NCLOB` datatypes explicitly, or to pass the flag
-``use_nchar_for_unicode=True`` to :func:`_sa.create_engine`,
-which will cause the
-SQLAlchemy dialect to use NCHAR/NCLOB for the :class:`.Unicode` /
+``use_nchar_for_unicode=True`` to :func:`_sa.create_engine`, which will cause
+the SQLAlchemy dialect to use NCHAR/NCLOB for the :class:`.Unicode` /
:class:`.UnicodeText` datatypes instead of VARCHAR/CLOB.
-.. versionchanged:: 1.3 The :class:`.Unicode` and :class:`.UnicodeText`
- datatypes now correspond to the ``VARCHAR2`` and ``CLOB`` Oracle datatypes
- unless the ``use_nchar_for_unicode=True`` is passed to the dialect
+.. versionchanged:: 1.3 The :class:`.Unicode` and :class:`.UnicodeText`
+ datatypes now correspond to the ``VARCHAR2`` and ``CLOB`` Oracle Database
+ datatypes unless the ``use_nchar_for_unicode=True`` is passed to the dialect
when :func:`_sa.create_engine` is called.
Encoding Errors
^^^^^^^^^^^^^^^
-For the unusual case that data in the Oracle database is present with a broken
+For the unusual case that data in Oracle Database is present with a broken
encoding, the dialect accepts a parameter ``encoding_errors`` which will be
passed to Unicode decoding functions in order to affect how decoding errors are
handled. The value is ultimately consumed by the Python `decode
-------------------------------------------------------------------------------
The cx_Oracle DBAPI has a deep and fundamental reliance upon the usage of the
-DBAPI ``setinputsizes()`` call. The purpose of this call is to establish the
+DBAPI ``setinputsizes()`` call. The purpose of this call is to establish the
datatypes that are bound to a SQL statement for Python values being passed as
parameters. While virtually no other DBAPI assigns any use to the
``setinputsizes()`` call, the cx_Oracle DBAPI relies upon it heavily in its
-interactions with the Oracle client interface, and in some scenarios it is not
-possible for SQLAlchemy to know exactly how data should be bound, as some
-settings can cause profoundly different performance characteristics, while
+interactions with the Oracle Database client interface, and in some scenarios
+it is not possible for SQLAlchemy to know exactly how data should be bound, as
+some settings can cause profoundly different performance characteristics, while
altering the type coercion behavior at the same time.
Users of the cx_Oracle dialect are **strongly encouraged** to read through
--------------
LOB datatypes refer to the "large object" datatypes such as CLOB, NCLOB and
-BLOB. Modern versions of cx_Oracle and oracledb are optimized for these
-datatypes to be delivered as a single buffer. As such, SQLAlchemy makes use of
-these newer type handlers by default.
+BLOB. Modern versions of cx_Oracle is optimized for these datatypes to be
+delivered as a single buffer. As such, SQLAlchemy makes use of these newer type
+handlers by default.
To disable the use of newer type handlers and deliver LOB objects as classic
buffered objects with a ``read()`` method, the parameter
``auto_convert_lobs=False`` may be passed to :func:`_sa.create_engine`,
which takes place only engine-wide.
-Two Phase Transactions Not Supported (use oracledb)
----------------------------------------------------
+Two Phase Transactions Not Supported
+------------------------------------
Two phase transactions are **not supported** under cx_Oracle due to poor driver
-support. The newer :ref:`oracledb` dialect however **does** support two phase
-transactions and should be preferred.
+support. The newer :ref:`oracledb` dialect however **does** support two phase
+transactions.
.. _cx_oracle_numeric:
``Decimal`` objects or float objects. When a :class:`.Numeric` object, or a
subclass such as :class:`.Float`, :class:`_oracle.DOUBLE_PRECISION` etc. is in
use, the :paramref:`.Numeric.asdecimal` flag determines if values should be
-coerced to ``Decimal`` upon return, or returned as float objects. To make
-matters more complicated under Oracle, Oracle's ``NUMBER`` type can also
-represent integer values if the "scale" is zero, so the Oracle-specific
-:class:`_oracle.NUMBER` type takes this into account as well.
+coerced to ``Decimal`` upon return, or returned as float objects. To make
+matters more complicated under Oracle Database, the ``NUMBER`` type can also
+represent integer values if the "scale" is zero, so the Oracle
+Database-specific :class:`_oracle.NUMBER` type takes this into account as well.
The cx_Oracle dialect makes extensive use of connection- and cursor-level
"outputtypehandler" callables in order to coerce numeric values as requested.
These callables are specific to the specific flavor of :class:`.Numeric` in
-use, as well as if no SQLAlchemy typing objects are present. There are
-observed scenarios where Oracle may sends incomplete or ambiguous information
-about the numeric types being returned, such as a query where the numeric types
-are buried under multiple levels of subquery. The type handlers do their best
-to make the right decision in all cases, deferring to the underlying cx_Oracle
-DBAPI for all those cases where the driver can make the best decision.
+use, as well as if no SQLAlchemy typing objects are present. There are
+observed scenarios where Oracle Database may send incomplete or ambiguous
+information about the numeric types being returned, such as a query where the
+numeric types are buried under multiple levels of subquery. The type handlers
+do their best to make the right decision in all cases, deferring to the
+underlying cx_Oracle DBAPI for all those cases where the driver can make the
+best decision.
When no typing objects are present, as when executing plain SQL strings, a
default "outputtypehandler" is present which will generally return numeric
# the MIT License: https://www.opensource.org/licenses/mit-license.php
# mypy: ignore-errors
-r"""
-.. dialect:: oracle+oracledb
+r""".. dialect:: oracle+oracledb
:name: python-oracledb
:dbapi: oracledb
:connectstring: oracle+oracledb://user:pass@hostname:port[/dbname][?service_name=<service>[&key=value&key=value...]]
Description
-----------
-python-oracledb is released by Oracle to supersede the cx_Oracle driver.
-It is fully compatible with cx_Oracle and features both a "thin" client
-mode that requires no dependencies, as well as a "thick" mode that uses
-the Oracle Client Interface in the same way as cx_Oracle.
+Python-oracledb is the Oracle Database driver for Python. It features a default
+"thin" client mode that requires no dependencies, and an optional "thick" mode
+that uses Oracle Client libraries. It supports SQLAlchemy features including
+two phase transactions and Asyncio.
-.. seealso::
-
- :ref:`cx_oracle` - all of cx_Oracle's notes apply to the oracledb driver
- as well, with the exception that oracledb supports two phase transactions.
+Python-oracle is the renamed, updated cx_Oracle driver. Oracle is no longer
+doing any releases in the cx_Oracle namespace.
The SQLAlchemy ``oracledb`` dialect provides both a sync and an async
implementation under the same dialect name. The proper version is
selected depending on how the engine is created:
* calling :func:`_sa.create_engine` with ``oracle+oracledb://...`` will
- automatically select the sync version, e.g.::
+ automatically select the sync version::
from sqlalchemy import create_engine
- sync_engine = create_engine("oracle+oracledb://scott:tiger@localhost/?service_name=XEPDB1")
+ sync_engine = create_engine("oracle+oracledb://scott:tiger@localhost?service_name=FREEPDB1")
-* calling :func:`_asyncio.create_async_engine` with
- ``oracle+oracledb://...`` will automatically select the async version,
- e.g.::
+* calling :func:`_asyncio.create_async_engine` with ``oracle+oracledb://...``
+ will automatically select the async version::
from sqlalchemy.ext.asyncio import create_async_engine
- asyncio_engine = create_async_engine("oracle+oracledb://scott:tiger@localhost/?service_name=XEPDB1")
+ asyncio_engine = create_async_engine("oracle+oracledb://scott:tiger@localhost?service_name=FREEPDB1")
-The asyncio version of the dialect may also be specified explicitly using the
-``oracledb_async`` suffix, as::
+ The asyncio version of the dialect may also be specified explicitly using the
+ ``oracledb_async`` suffix::
- from sqlalchemy.ext.asyncio import create_async_engine
- asyncio_engine = create_async_engine("oracle+oracledb_async://scott:tiger@localhost/?service_name=XEPDB1")
+ from sqlalchemy.ext.asyncio import create_async_engine
+ asyncio_engine = create_async_engine("oracle+oracledb_async://scott:tiger@localhost?service_name=FREEPDB1")
.. versionadded:: 2.0.25 added support for the async version of oracledb.
Thick mode support
------------------
-By default the ``python-oracledb`` is started in thin mode, that does not
-require oracle client libraries to be installed in the system. The
-``python-oracledb`` driver also support a "thick" mode, that behaves
-similarly to ``cx_oracle`` and requires that Oracle Client Interface (OCI)
-is installed.
+By default, the python-oracledb driver runs in a "thin" mode that does not
+require Oracle Client libraries to be installed. The driver also supports a
+"thick" mode that uses Oracle Client libraries to get functionality such as
+Oracle Application Continuity.
-To enable this mode, the user may call ``oracledb.init_oracle_client``
-manually, or by passing the parameter ``thick_mode=True`` to
-:func:`_sa.create_engine`. To pass custom arguments to ``init_oracle_client``,
-like the ``lib_dir`` path, a dict may be passed to this parameter, as in::
+To enable thick mode, call `oracledb.init_oracle_client()
+<https://python-oracledb.readthedocs.io/en/latest/api_manual/module.html#oracledb.init_oracle_client>`_
+explicitly, or pass the parameter ``thick_mode=True`` to
+:func:`_sa.create_engine`. To pass custom arguments to
+``init_oracle_client()``, like the ``lib_dir`` path, a dict may be passed, for
+example::
engine = sa.create_engine("oracle+oracledb://...", thick_mode={
- "lib_dir": "/path/to/oracle/client/lib", "driver_name": "my-app"
+ "lib_dir": "/path/to/oracle/client/lib",
+ "config_dir": "/path/to/network_config_file_directory",
+ "driver_name": "my-app : 1.0.0"
})
+Note that passing a ``lib_dir`` path should only be done on macOS or
+Windows. On Linux it does not behave as you might expect.
+
.. seealso::
- https://python-oracledb.readthedocs.io/en/latest/api_manual/module.html#oracledb.init_oracle_client
+ python-oracledb documentation `Enabling python-oracledb Thick mode
+ <https://python-oracledb.readthedocs.io/en/latest/user_guide/initialization.html#enabling-python-oracledb-thick-mode>`_
+
+Connecting to Oracle Database
+-----------------------------
+
+python-oracledb provides several methods of indicating the target database.
+The dialect translates from a series of different URL forms.
+
+Given the hostname, port and service name of the target database, you can
+connect in SQLAlchemy using the ``service_name`` query string parameter::
+
+ engine = create_engine("oracle+oracledb://scott:tiger@hostname:port?service_name=myservice")
+
+Connecting with Easy Connect strings
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+You can pass any valid python-oracledb connection string as the ``dsn`` key
+value in a :paramref:`_sa.create_engine.connect_args` dictionary. See
+python-oracledb documentation `Oracle Net Services Connection Strings
+<https://python-oracledb.readthedocs.io/en/latest/user_guide/connection_handling.html#oracle-net-services-connection-strings>`_.
+
+For example to use an `Easy Connect string
+<https://download.oracle.com/ocomdocs/global/Oracle-Net-Easy-Connect-Plus.pdf>`_
+with a timeout to prevent connection establishment from hanging if the network
+transport to the database cannot be establishd in 30 seconds, and also setting
+a keep-alive time of 60 seconds to stop idle network connections from being
+terminated by a firewall::
+
+ e = create_engine(
+ "oracle+oracledb://@",
+ connect_args={
+ "user": "scott",
+ "password": "tiger",
+ "dsn": "hostname:port/myservice?transport_connect_timeout=30&expire_time=60"
+ }
+ )
+
+Note that although the SQLAlchemy URL syntax ``hostname:port/dbname`` looks
+like Oracle's Easy Connect syntax, it is different. It requires a system
+identifier (SID) for the ``dbname`` component of the URL::
+
+ engine = create_engine("oracle+oracledb://scott:tiger@hostname:port/sid")
+
+Easy Connect syntax does not support SIDs. It uses services names, which are
+the preferred choice for connecting to Oracle Database
+
+Passing python-oracledb connect arguments
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+Other python-oracledb driver `connection options
+<https://python-oracledb.readthedocs.io/en/latest/api_manual/module.html#oracledb.connect>`_
+can be passed in ``connect_args``. For example::
+
+ e = create_engine(
+ "oracle+oracledb://@",
+ connect_args={
+ "user": "scott",
+ "password": "tiger",
+ "dsn": "hostname:port/myservice",
+ "events": True,
+ "mode": oracledb.AUTH_MODE_SYSDBA
+ }
+ )
+
+Connecting with tnsnames.ora TNS aliases
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+If no port, database name, or service name is provided, the dialect will use an
+Oracle Database DSN "connection string". This takes the "hostname" portion of
+the URL as the data source name. For example, if the ``tnsnames.ora`` file
+contains a `TNS Alias
+<https://python-oracledb.readthedocs.io/en/latest/user_guide/connection_handling.html#tns-aliases-for-connection-strings>`_
+of ``myalias`` as below::
+
+ myalias =
+ (DESCRIPTION =
+ (ADDRESS = (PROTOCOL = TCP)(HOST = mymachine.example.com)(PORT = 1521))
+ (CONNECT_DATA =
+ (SERVER = DEDICATED)
+ (SERVICE_NAME = orclpdb1)
+ )
+ )
+
+The python-oracledb dialect connects to this database service when ``myalias`` is the
+hostname portion of the URL, without specifying a port, database name or
+``service_name``::
+
+ engine = create_engine("oracle+oracledb://scott:tiger@myalias")
+
+Connecting to Oracle Autonomous Database
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+Users of Oracle Autonomous Database should use either use the TNS Alias URL
+shown above, or pass the TNS Alias as the ``dsn`` key value in a
+:paramref:`_sa.create_engine.connect_args` dictionary.
+
+If Oracle Autonomous Database is configured for mutual TLS ("mTLS")
+connections, then additional configuration is required as shown in `Connecting
+to Oracle Cloud Autonomous Databases
+<https://python-oracledb.readthedocs.io/en/latest/user_guide/connection_handling.html#connecting-to-oracle-cloud-autonomous-databases>`_. In
+summary, Thick mode users should configure file locations and set the wallet
+path in ``sqlnet.ora`` appropriately::
+
+ e = create_engine(
+ "oracle+oracledb://@",
+ thick_mode={
+ # directory containing tnsnames.ora and cwallet.so
+ "config_dir": "/opt/oracle/wallet_dir",
+ },
+ connect_args={
+ "user": "scott",
+ "password": "tiger",
+ "dsn": "mydb_high"
+ }
+ )
+
+Thin mode users of mTLS should pass the appropriate directories and PEM wallet
+password when creating the engine, similar to::
+
+ e = create_engine(
+ "oracle+oracledb://@",
+ connect_args={
+ "user": "scott",
+ "password": "tiger",
+ "dsn": "mydb_high",
+ "config_dir": "/opt/oracle/wallet_dir", # directory containing tnsnames.ora
+ "wallet_location": "/opt/oracle/wallet_dir", # directory containing ewallet.pem
+ "wallet_password": "top secret" # password for the PEM file
+ }
+ )
+
+Typically ``config_dir`` and ``wallet_location`` are the same directory, which
+is where the Oracle Autonomous Database wallet zip file was extracted. Note
+this directory should be protected.
+
+Connection Pooling
+------------------
+
+Applications with multiple concurrent users should use connection pooling. A
+minimal sized connection pool is also beneficial for long-running, single-user
+applications that do not frequently use a connection.
+
+The python-oracledb driver provides its own connection pool implementation that
+may be used in place of SQLAlchemy's pooling functionality. The driver pool
+gives support for high availability features such as dead connection detection,
+connection draining for planned database downtime, support for Oracle
+Application Continuity and Transparent Application Continuity, and gives
+support for `Database Resident Connection Pooling (DRCP)
+<https://python-oracledb.readthedocs.io/en/latest/user_guide/connection_handling.html#database-resident-connection-pooling-drcp>`_.
+
+To take advantage of python-oracledb's pool, use the
+:paramref:`_sa.create_engine.creator` parameter to provide a function that
+returns a new connection, along with setting
+:paramref:`_sa.create_engine.pool_class` to ``NullPool`` to disable
+SQLAlchemy's pooling::
+
+ import oracledb
+ from sqlalchemy import create_engine
+ from sqlalchemy import text
+ from sqlalchemy.pool import NullPool
+
+ # Uncomment to use the optional python-oracledb Thick mode.
+ # Review the python-oracledb doc for the appropriate parameters
+ #oracledb.init_oracle_client(<your parameters>)
+
+ pool = oracledb.create_pool(user="scott", password="tiger", dsn="localhost:1521/freepdb1",
+ min=1, max=4, increment=1)
+ engine = create_engine("oracle+oracledb://", creator=pool.acquire, poolclass=NullPool)
+
+The above engine may then be used normally. Internally, python-oracledb handles
+connection pooling::
+
+ with engine.connect() as conn:
+ print(conn.scalar(text("select 1 from dual")))
+
+.. _drcp:
+
+Using Oracle Database Resident Connection Pooling (DRCP)
+--------------------------------------------------------
+
+When using Oracle Database's Database Resident Connection Pooling (DRCP), the
+best practice is to specify a connection class and "purity". Refer to the
+`python-oracledb documentation on DRCP
+<https://python-oracledb.readthedocs.io/en/latest/user_guide/connection_handling.html#database-resident-connection-pooling-drcp>`_.
+For example::
+
+ import oracledb
+ from sqlalchemy import create_engine
+ from sqlalchemy import text
+ from sqlalchemy.pool import NullPool
+
+ # Uncomment to use the optional python-oracledb Thick mode.
+ # Review the python-oracledb doc for the appropriate parameters
+ #oracledb.init_oracle_client(<your parameters>)
+
+ pool = oracledb.create_pool(user="scott", password="tiger", dsn="localhost:1521/freepdb1",
+ min=1, max=4, increment=1,
+ cclass="MYCLASS", purity=oracledb.PURITY_SELF)
+ engine = create_engine("oracle+oracledb://", creator=pool.acquire, poolclass=NullPool)
+
+The above engine may then be used normally where python-oracledb handles
+application connection pooling and Oracle Database additionally uses DRCP::
+
+ with engine.connect() as conn:
+ print(conn.scalar(text("select 1 from dual")))
+
+If you wish to use different connection classes or purities for different
+connections, then wrap ``pool.acquire()``::
+
+ import oracledb
+ from sqlalchemy import create_engine
+ from sqlalchemy import text
+ from sqlalchemy.pool import NullPool
+
+ # Uncomment to use python-oracledb Thick mode.
+ # Review the python-oracledb doc for the appropriate parameters
+ #oracledb.init_oracle_client(<your parameters>)
+
+ pool = oracledb.create_pool(user="scott", password="tiger", dsn="localhost:1521/freepdb1",
+ min=1, max=4, increment=1,
+ cclass="MYCLASS", purity=oracledb.PURITY_SELF)
+
+ def creator():
+ return pool.acquire(cclass="MYOTHERCLASS", purity=oracledb.PURITY_NEW)
+
+ engine = create_engine("oracle+oracledb://", creator=creator, poolclass=NullPool)
+
+Engine Options consumed by the SQLAlchemy oracledb dialect outside of the driver
+--------------------------------------------------------------------------------
+
+There are also options that are consumed by the SQLAlchemy oracledb dialect
+itself. These options are always passed directly to :func:`_sa.create_engine`,
+such as::
+
+ e = create_engine(
+ "oracle+oracledb://user:pass@tnsalias", arraysize=500)
+
+The parameters accepted by the oracledb dialect are as follows:
+
+* ``arraysize`` - set the driver cursor.arraysize value. It defaults to
+ ``None``, indicating that the driver default value of 100 should be used.
+ This setting controls how many rows are buffered when fetching rows, and can
+ have a significant effect on performance if increased for queries that return
+ large numbers of rows.
+
+ .. versionchanged:: 2.0.26 - changed the default value from 50 to None,
+ to use the default value of the driver itself.
+
+* ``auto_convert_lobs`` - defaults to True; See :ref:`oracledb_lob`.
+
+* ``coerce_to_decimal`` - see :ref:`oracledb_numeric` for detail.
+
+* ``encoding_errors`` - see :ref:`oracledb_unicode_encoding_errors` for detail.
+
+.. _oracledb_unicode:
-Two Phase Transactions Supported
---------------------------------
+Unicode
+-------
-Two phase transactions are fully supported under oracledb. Starting with
-oracledb 2.3 two phase transactions are supported also in thin mode. APIs
-for two phase transactions are provided at the Core level via
-:meth:`_engine.Connection.begin_twophase` and :paramref:`_orm.Session.twophase`
-for transparent ORM use.
+As is the case for all DBAPIs under Python 3, all strings are inherently
+Unicode strings.
+
+Ensuring the Correct Client Encoding
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+In python-oracledb, the encoding used for all character data is "UTF-8".
+
+Unicode-specific Column datatypes
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+The Core expression language handles unicode data by use of the
+:class:`.Unicode` and :class:`.UnicodeText` datatypes. These types correspond
+to the VARCHAR2 and CLOB Oracle Database datatypes by default. When using
+these datatypes with Unicode data, it is expected that the database is
+configured with a Unicode-aware character set so that the VARCHAR2 and CLOB
+datatypes can accommodate the data.
+
+In the case that Oracle Database is not configured with a Unicode character
+set, the two options are to use the :class:`_types.NCHAR` and
+:class:`_oracle.NCLOB` datatypes explicitly, or to pass the flag
+``use_nchar_for_unicode=True`` to :func:`_sa.create_engine`, which will cause
+the SQLAlchemy dialect to use NCHAR/NCLOB for the :class:`.Unicode` /
+:class:`.UnicodeText` datatypes instead of VARCHAR/CLOB.
+
+.. versionchanged:: 1.3 The :class:`.Unicode` and :class:`.UnicodeText`
+ datatypes now correspond to the ``VARCHAR2`` and ``CLOB`` Oracle Database
+ datatypes unless the ``use_nchar_for_unicode=True`` is passed to the dialect
+ when :func:`_sa.create_engine` is called.
+
+
+.. _oracledb_unicode_encoding_errors:
+
+Encoding Errors
+^^^^^^^^^^^^^^^
+
+For the unusual case that data in Oracle Database is present with a broken
+encoding, the dialect accepts a parameter ``encoding_errors`` which will be
+passed to Unicode decoding functions in order to affect how decoding errors are
+handled. The value is ultimately consumed by the Python `decode
+<https://docs.python.org/3/library/stdtypes.html#bytes.decode>`_ function, and
+is passed both via python-oracledb's ``encodingErrors`` parameter consumed by
+``Cursor.var()``, as well as SQLAlchemy's own decoding function, as the
+python-oracledb dialect makes use of both under different circumstances.
+
+.. versionadded:: 1.3.11
+
+
+.. _oracledb_setinputsizes:
+
+Fine grained control over python-oracledb data binding with setinputsizes
+-------------------------------------------------------------------------
+
+The python-oracle DBAPI has a deep and fundamental reliance upon the usage of
+the DBAPI ``setinputsizes()`` call. The purpose of this call is to establish
+the datatypes that are bound to a SQL statement for Python values being passed
+as parameters. While virtually no other DBAPI assigns any use to the
+``setinputsizes()`` call, the python-oracledb DBAPI relies upon it heavily in
+its interactions with the Oracle Database, and in some scenarios it is not
+possible for SQLAlchemy to know exactly how data should be bound, as some
+settings can cause profoundly different performance characteristics, while
+altering the type coercion behavior at the same time.
+
+Users of the oracledb dialect are **strongly encouraged** to read through
+python-oracledb's list of built-in datatype symbols at `Database Types
+<https://python-oracledb.readthedocs.io/en/latest/api_manual/module.html#database-types>`_
+Note that in some cases, significant performance degradation can occur when
+using these types vs. not.
+
+On the SQLAlchemy side, the :meth:`.DialectEvents.do_setinputsizes` event can
+be used both for runtime visibility (e.g. logging) of the setinputsizes step as
+well as to fully control how ``setinputsizes()`` is used on a per-statement
+basis.
+
+.. versionadded:: 1.2.9 Added :meth:`.DialectEvents.setinputsizes`
+
+
+Example 1 - logging all setinputsizes calls
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+The following example illustrates how to log the intermediary values from a
+SQLAlchemy perspective before they are converted to the raw ``setinputsizes()``
+parameter dictionary. The keys of the dictionary are :class:`.BindParameter`
+objects which have a ``.key`` and a ``.type`` attribute::
+
+ from sqlalchemy import create_engine, event
+
+ engine = create_engine("oracle+oracledb://scott:tiger@localhost:1521?service_name=freepdb1")
+
+ @event.listens_for(engine, "do_setinputsizes")
+ def _log_setinputsizes(inputsizes, cursor, statement, parameters, context):
+ for bindparam, dbapitype in inputsizes.items():
+ log.info(
+ "Bound parameter name: %s SQLAlchemy type: %r "
+ "DBAPI object: %s",
+ bindparam.key, bindparam.type, dbapitype)
+
+Example 2 - remove all bindings to CLOB
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+For performance, fetching LOB datatypes from Oracle Database is set by default
+for the ``Text`` type within SQLAlchemy. This setting can be modified as
+follows::
+
+
+ from sqlalchemy import create_engine, event
+ from oracledb import CLOB
+
+ engine = create_engine("oracle+oracledb://scott:tiger@localhost:1521?service_name=freepdb1")
+
+ @event.listens_for(engine, "do_setinputsizes")
+ def _remove_clob(inputsizes, cursor, statement, parameters, context):
+ for bindparam, dbapitype in list(inputsizes.items()):
+ if dbapitype is CLOB:
+ del inputsizes[bindparam]
+
+.. _oracledb_returning:
+
+RETURNING Support
+-----------------
+
+The oracledb dialect implements RETURNING using OUT parameters. The dialect
+supports RETURNING fully.
+
+.. _oracledb_lob:
+
+LOB Datatypes
+--------------
+
+LOB datatypes refer to the "large object" datatypes such as CLOB, NCLOB and
+BLOB. Oracle Database can efficiently return these datatypes as a single
+buffer. SQLAlchemy makes use of type handlers to do this by default.
+
+To disable the use of the type handlers and deliver LOB objects as classic
+buffered objects with a ``read()`` method, the parameter
+``auto_convert_lobs=False`` may be passed to :func:`_sa.create_engine`.
+
+Two Phase Transaction Support
+-----------------------------
+
+Two phase transactions are fully supported with python-oracledb. (Thin mode
+requires python-oracledb 2.3). APIs for two phase transactions are provided at
+the Core level via :meth:`_engine.Connection.begin_twophase` and
+:paramref:`_orm.Session.twophase` for transparent ORM use.
.. versionchanged:: 2.0.32 added support for two phase transactions
-.. versionadded:: 2.0.0 added support for oracledb driver.
+.. versionadded:: 2.0.0 added support for the python-oracledb driver.
+
+.. _oracledb_numeric:
+
+Precision Numerics
+------------------
+
+SQLAlchemy's numeric types can handle receiving and returning values as Python
+``Decimal`` objects or float objects. When a :class:`.Numeric` object, or a
+subclass such as :class:`.Float`, :class:`_oracle.DOUBLE_PRECISION` etc. is in
+use, the :paramref:`.Numeric.asdecimal` flag determines if values should be
+coerced to ``Decimal`` upon return, or returned as float objects. To make
+matters more complicated under Oracle Database, the ``NUMBER`` type can also
+represent integer values if the "scale" is zero, so the Oracle
+Database-specific :class:`_oracle.NUMBER` type takes this into account as well.
+
+The oracledb dialect makes extensive use of connection- and cursor-level
+"outputtypehandler" callables in order to coerce numeric values as requested.
+These callables are specific to the specific flavor of :class:`.Numeric` in
+use, as well as if no SQLAlchemy typing objects are present. There are
+observed scenarios where Oracle Database may send incomplete or ambiguous
+information about the numeric types being returned, such as a query where the
+numeric types are buried under multiple levels of subquery. The type handlers
+do their best to make the right decision in all cases, deferring to the
+underlying python-oracledb DBAPI for all those cases where the driver can make
+the best decision.
+
+When no typing objects are present, as when executing plain SQL strings, a
+default "outputtypehandler" is present which will generally return numeric
+values which specify precision and scale as Python ``Decimal`` objects. To
+disable this coercion to decimal for performance reasons, pass the flag
+``coerce_to_decimal=False`` to :func:`_sa.create_engine`::
+
+ engine = create_engine("oracle+oracledb://scott:tiger@tnsalias", coerce_to_decimal=False)
+
+The ``coerce_to_decimal`` flag only impacts the results of plain string
+SQL statements that are not otherwise associated with a :class:`.Numeric`
+SQLAlchemy type (or a subclass of such).
+
+.. versionchanged:: 1.2 The numeric handling system for the oracle dialects has
+ been reworked to take advantage of newer driver features as well as better
+ integration of outputtypehandlers.
""" # noqa
from __future__ import annotations
def _get_version(conn):
# this is the suggested way of finding the mode, from
- # https://python-oracledb.readthedocs.io/en/latest/user_guide/tracing.html#vsessconinfo
+ # https://python-oracledb.readthedocs.io/en/latest/user_guide/tracing.html#finding-the-python-oracledb-mode
sql = (
"SELECT UNIQUE CLIENT_DRIVER "
"FROM V$SESSION_CONNECT_INFO "