SQLAlchemy 2.0 Documentation
Dialects
- PostgreSQL
- MySQL and MariaDB
- SQLite
- Oracle¶
- Support for the Oracle Database database.
- Auto Increment Behavior
- Transaction Isolation Level / Autocommit
- Identifier Casing
- Maximum Identifier Lengths
- LIMIT/OFFSET/FETCH Support
- RETURNING Support
- ON UPDATE CASCADE
- Oracle Database 8 Compatibility
- Synonym/DBLINK Reflection
- Constraint Reflection
- Table names with SYSTEM/SYSAUX tablespaces
- FLOAT / DOUBLE Support and Behaviors
- DateTime Compatibility
- Oracle Database Table Options
- Oracle Database Specific Index Options
- Oracle Database Data Types
- python-oracledb
- DBAPI
- Connecting
- Description
- Thick mode support
- Connecting to Oracle Database
- Connection Pooling
- Using Oracle Database Resident Connection Pooling (DRCP)
- Engine Options consumed by the SQLAlchemy oracledb dialect outside of the driver
- Unicode
- Fine grained control over python-oracledb data binding with setinputsizes
- LOB Datatypes
- RETURNING Support
- Two Phase Transaction Support
- Precision Numerics
- cx_Oracle
- DBAPI
- Connecting
- Description
- DSN vs. Hostname connections
- Passing cx_Oracle connect arguments
- Options consumed by the SQLAlchemy cx_Oracle dialect outside of the driver
- Using cx_Oracle SessionPool
- Using Oracle Database Resident Connection Pooling (DRCP)
- Unicode
- Fine grained control over cx_Oracle data binding performance with setinputsizes
- LOB Datatypes
- RETURNING Support
- Two Phase Transactions Not Supported
- Precision Numerics
- Microsoft SQL Server
Project Versions
- Previous: SQLite
- Next: Microsoft SQL Server
- Up: Home
- On this page:
- Oracle
- Support for the Oracle Database database.
- Auto Increment Behavior
- Transaction Isolation Level / Autocommit
- Identifier Casing
- Maximum Identifier Lengths
- LIMIT/OFFSET/FETCH Support
- RETURNING Support
- ON UPDATE CASCADE
- Oracle Database 8 Compatibility
- Synonym/DBLINK Reflection
- Constraint Reflection
- Table names with SYSTEM/SYSAUX tablespaces
- FLOAT / DOUBLE Support and Behaviors
- DateTime Compatibility
- Oracle Database Table Options
- Oracle Database Specific Index Options
- Oracle Database Data Types
- python-oracledb
- DBAPI
- Connecting
- Description
- Thick mode support
- Connecting to Oracle Database
- Connection Pooling
- Using Oracle Database Resident Connection Pooling (DRCP)
- Engine Options consumed by the SQLAlchemy oracledb dialect outside of the driver
- Unicode
- Fine grained control over python-oracledb data binding with setinputsizes
- LOB Datatypes
- RETURNING Support
- Two Phase Transaction Support
- Precision Numerics
- cx_Oracle
- DBAPI
- Connecting
- Description
- DSN vs. Hostname connections
- Passing cx_Oracle connect arguments
- Options consumed by the SQLAlchemy cx_Oracle dialect outside of the driver
- Using cx_Oracle SessionPool
- Using Oracle Database Resident Connection Pooling (DRCP)
- Unicode
- Fine grained control over cx_Oracle data binding performance with setinputsizes
- LOB Datatypes
- RETURNING Support
- Two Phase Transactions Not Supported
- Precision Numerics
Oracle¶
Support for the Oracle Database database.
The following table summarizes current support levels for database release versions.
Support type |
Versions |
---|---|
11+ |
|
9+ |
DBAPI Support¶
The following dialect/DBAPI options are available. Please refer to individual DBAPI sections for connect information.
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 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 Database 12 and above)¶
Starting from version 12, Oracle Database can make use of identity columns
using the Identity
to specify the autoincrementing behavior:
t = Table(
"mytable",
metadata,
Column("id", Integer, Identity(start=3), primary_key=True),
Column(...),
...,
)
The CREATE TABLE for the above Table
object would be:
CREATE TABLE mytable (
id INTEGER GENERATED BY DEFAULT AS IDENTITY (START WITH 3),
...,
PRIMARY KEY (id)
)
The 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 Database
supports setting Identity.always
to None
to use the
default generated mode, rendering GENERATED AS IDENTITY in the DDL. It also supports
setting Identity.on_null
to True
to specify ON NULL
in conjunction with a ‘BY DEFAULT’ identity column.
Using a SEQUENCE (all Oracle Database versions)¶
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),
Column(...),
...,
)
This step is also required when using table reflection, i.e. autoload_with=engine:
t = Table(
"mytable",
metadata,
Column("id", Integer, Sequence("id_seq", start=1), primary_key=True),
autoload_with=engine,
)
Transaction Isolation Level / Autocommit¶
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:
connection = engine.connect()
connection = connection.execution_options(isolation_level="AUTOCOMMIT")
For READ COMMITTED
and SERIALIZABLE
, the Oracle Database 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:
READ COMMITTED
AUTOCOMMIT
SERIALIZABLE
Note
The implementation for the
Connection.get_isolation_level()
method as implemented by the
Oracle Database 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 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 Database
installations.
The python-oracledb and cx_Oracle dialects attempt to call the
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
Connection.execution_options()
method. In the common event
that the 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.
New in version 1.3.16: added support for AUTOCOMMIT to the cx_Oracle dialect as well as the notion of a default isolation level
New in version 1.3.21: Added support for SERIALIZABLE as well as live reading of the isolation level.
Changed in version 1.3.22: In the event that the default isolation level cannot be read due to permissions on the v$transaction view as is common in Oracle installations, the default isolation level is hardcoded to “READ COMMITTED” which was the behavior prior to 1.3.21.
Identifier Casing¶
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 Database 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 Database, 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.
Maximum Identifier Lengths¶
SQLAlchemy is sensitive to the maximum identifier length supported by Oracle Database. This affects generated SQL label names as well as the generation of constraint names, particularly in the case where the constraint naming convention feature described at Configuring Constraint Naming Conventions is being used.
Oracle Database 12.2 increased the default maximum identifier length from 30 to
128. As of SQLAlchemy 1.4, the default maximum identifier length for the Oracle
dialects is 128 characters. Upon first connection, the maximum length actually
supported by the database is obtained. In all cases, setting the
create_engine.max_identifier_length
parameter will bypass this
change and the value given will be used as is:
engine = create_engine(
"oracle+oracledb://scott:tiger@localhost:1521?service_name=freepdb1",
max_identifier_length=30,
)
If create_engine.max_identifier_length
is not set, the oracledb
dialect internally uses the max_identifier_length
attribute available on
driver connections since python-oracledb version 2.5. When using an older
driver version, or using the cx_Oracle dialect, SQLAlchemy will instead attempt
to use the query SELECT value FROM v$parameter WHERE name = 'compatible'
upon first connect in order to determine the effective compatibility version of
the database. The “compatibility” version is a version number that is
independent of the actual database version. It is used to assist database
migration. It is configured by an Oracle Database initialization parameter. The
compatibility version then determines the maximum allowed identifier length for
the database. If the V$ view is not available, the database version information
is used instead.
The maximum identifier length comes into play both when generating anonymized SQL labels in SELECT statements, but more crucially when generating constraint names from a naming convention. It is this area that has created the need for SQLAlchemy to change this default conservatively. For example, the following naming convention produces two very different constraint names based on the identifier length:
from sqlalchemy import Column
from sqlalchemy import Index
from sqlalchemy import Integer
from sqlalchemy import MetaData
from sqlalchemy import Table
from sqlalchemy.dialects import oracle
from sqlalchemy.schema import CreateIndex
m = MetaData(naming_convention={"ix": "ix_%(column_0N_name)s"})
t = Table(
"t",
m,
Column("some_column_name_1", Integer),
Column("some_column_name_2", Integer),
Column("some_column_name_3", Integer),
)
ix = Index(
None,
t.c.some_column_name_1,
t.c.some_column_name_2,
t.c.some_column_name_3,
)
oracle_dialect = oracle.dialect(max_identifier_length=30)
print(CreateIndex(ix).compile(dialect=oracle_dialect))
With an identifier length of 30, the above CREATE INDEX looks like:
CREATE INDEX ix_some_column_name_1s_70cd ON t
(some_column_name_1, some_column_name_2, some_column_name_3)
However with length of 128, it becomes:
.. sourcecode:: sql
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 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
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.
Changed in version 1.4: the default max_identifier_length for Oracle Database is 128 characters, which is adjusted down to 30 upon first connect if the Oracle Database, or its compatibility setting, are lower than version 12.2.
LIMIT/OFFSET/FETCH Support¶
Methods like Select.limit()
and 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
Select.fetch()
method.
Changed in version 2.0: the Oracle Database dialects now use FETCH FIRST N
ROW / OFFSET N ROWS
for all Select.limit()
and
Select.offset()
usage including within the ORM and legacy
Query
. To force the legacy behavior using window functions,
specify the enable_offset_fetch=False
dialect parameter to
create_engine()
.
The use of FETCH FIRST / OFFSET
may be disabled on any Oracle Database
version by passing enable_offset_fetch=False
to 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
Database prior to 12c.
When using legacy mode, or when a Select
statement with limit/offset
is embedded in a compound statement, an emulated approach for LIMIT / OFFSET
based on window functions is used, which involves creation of a subquery using
ROW_NUMBER
that is prone to performance issues as well as SQL construction
issues for complex statements. However, this approach is supported by all
Oracle Database versions. See notes below.
Notes on LIMIT / OFFSET emulation (when fetch() method cannot be used)¶
If using Select.limit()
and Select.offset()
, or with the
ORM the Query.limit()
and Query.offset()
methods on an
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 https://blogs.oracle.com/oraclemagazine/on-rownum-and-limiting-results .
the “FIRST_ROWS()” optimization keyword is not used by default. To enable the usage of this optimization directive, specify
optimize_limits=True
tocreate_engine()
.Changed in version 1.4: The Oracle Database dialect renders limit/offset integer values using a “post compile” scheme which renders the integer directly before passing the statement to the cursor for execution. The
use_binds_for_limits
flag no longer has an effect.
RETURNING Support¶
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 executemany statements). Multiple rows may be
returned as well.
Changed in version 2.0: the Oracle Database backend has full support for RETURNING on parity with other backends.
ON UPDATE CASCADE¶
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 cascading updates - specify ForeignKey objects using the “deferrable=True, initially=’deferred’” keyword arguments, and specify “passive_updates=False” on each relationship().
Oracle Database 8 Compatibility¶
Warning
The status of Oracle Database 8 compatibility is not known for SQLAlchemy 2.0.
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 makes use of Oracle’s (+) operator.
the NVARCHAR2 and NCLOB datatypes are no longer generated as DDL when the
Unicode
is used - VARCHAR2 and CLOB are issued instead. This because these types don’t seem to work correctly on Oracle 8 even though they are available. TheNVARCHAR
andNCLOB
types will always generate NVARCHAR2 and NCLOB.
Synonym/DBLINK Reflection¶
When using reflection with Table objects, the dialect can optionally search
for tables indicated by synonyms, either in local or remote schemas or
accessed over DBLINK, by passing the flag oracle_resolve_synonyms=True
as
a keyword argument to the Table
construct:
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
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 Database
dialects know how to locate the table’s information using DBLINK syntax(e.g.
@dblink
).
oracle_resolve_synonyms
is accepted wherever reflection arguments are
accepted, including methods such as MetaData.reflect()
and
Inspector.get_columns()
.
If synonyms are not in use, this flag should be left disabled.
Constraint Reflection¶
The Oracle Database 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
Inspector.get_foreign_keys()
,
Inspector.get_unique_constraints()
,
Inspector.get_check_constraints()
, and
Inspector.get_indexes()
.
Changed in version 1.2: The Oracle Database dialect can now reflect UNIQUE and CHECK constraints.
When using reflection at the Table
level, the
Table
will also include these constraints.
Note the following caveats:
When using the
Inspector.get_check_constraints()
method, Oracle Database 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 flaginclude_all=True
:from sqlalchemy import create_engine, inspect engine = create_engine( "oracle+oracledb://scott:tiger@localhost:1521?service_name=freepdb1" ) inspector = inspect(engine) all_check_constraints = inspector.get_check_constraints( "some_table", include_all=True )
in most cases, when reflecting a
Table
, a UNIQUE constraint will not be available as aUniqueConstraint
object, as Oracle Database mirrors unique constraints with a UNIQUE index in most cases (the exception seems to be when two or more unique constraints represent the same columns); theTable
will instead represent these usingIndex
with theunique=True
flag set.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.
Table names with SYSTEM/SYSAUX tablespaces¶
The Inspector.get_table_names()
and
Inspector.get_temp_table_names()
methods each return a list of table names for the current engine. These methods
are also part of the reflection which occurs within an operation such as
MetaData.reflect()
. By default,
these operations exclude the SYSTEM
and SYSAUX
tablespaces from the operation. In order to change this, the
default list of tablespaces excluded can be changed at the engine level using
the exclude_tablespaces
parameter:
# exclude SYSAUX and SOME_TABLESPACE, but not SYSTEM
e = create_engine(
"oracle+oracledb://scott:tiger@localhost:1521/?service_name=freepdb1",
exclude_tablespaces=["SYSAUX", "SOME_TABLESPACE"],
)
FLOAT / DOUBLE Support and Behaviors¶
The SQLAlchemy Float
and Double
datatypes are generic
datatypes that resolve to the “least surprising” datatype for a given backend.
For Oracle Database, this means they resolve to the FLOAT
and DOUBLE
types:
>>> from sqlalchemy import cast, literal, Float
>>> from sqlalchemy.dialects import oracle
>>> float_datatype = Float()
>>> print(cast(literal(5.0), float_datatype).compile(dialect=oracle.dialect()))
CAST(:param_1 AS FLOAT)
Oracle’s FLOAT
/ DOUBLE
datatypes are aliases for NUMBER
. Oracle
Database stores NUMBER
values with full precision, not floating point
precision, which means that FLOAT
/ DOUBLE
do not actually behave like
native FP values. Oracle Database instead offers special datatypes
BINARY_FLOAT
and BINARY_DOUBLE
to deliver real 4- and 8- byte FP
values.
SQLAlchemy supports these datatypes directly using BINARY_FLOAT
and
BINARY_DOUBLE
. To use the Float
or Double
datatypes in a database agnostic way, while allowing Oracle backends to utilize
one of these types, use the TypeEngine.with_variant()
method to set up a
variant:
>>> from sqlalchemy import cast, literal, Float
>>> from sqlalchemy.dialects import oracle
>>> float_datatype = Float().with_variant(oracle.BINARY_FLOAT(), "oracle")
>>> print(cast(literal(5.0), float_datatype).compile(dialect=oracle.dialect()))
CAST(:param_1 AS BINARY_FLOAT)
E.g. to use this datatype in a Table
definition:
my_table = Table(
"my_table",
metadata,
Column(
"fp_data", Float().with_variant(oracle.BINARY_FLOAT(), "oracle")
),
)
DateTime Compatibility¶
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 Database dialects provide a type DATE
which is a
subclass of 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
DATE
type is used.
Oracle Database Table Options¶
The CREATE TABLE phrase supports the following options with Oracle Database
dialects in conjunction with the Table
construct:
ON COMMIT
:Table( "some_table", metadata, ..., prefixes=["GLOBAL TEMPORARY"], oracle_on_commit="PRESERVE ROWS", )
COMPRESS
:Table( "mytable", metadata, Column("data", String(32)), oracle_compress=True ) Table("mytable", metadata, Column("data", String(32)), oracle_compress=6)
The
oracle_compress
parameter accepts either an integer compression level, orTrue
to use the default compression level.TABLESPACE
:Table("mytable", metadata, ..., oracle_tablespace="EXAMPLE_TABLESPACE")
The
oracle_tablespace
parameter specifies the tablespace in which the table is to be created. This is useful when you want to create a table in a tablespace other than the default tablespace of the user.New in version 2.0.37.
Oracle Database Specific Index Options¶
Bitmap Indexes¶
You can specify the oracle_bitmap
parameter to create a bitmap index
instead of a B-tree index:
Index("my_index", my_table.c.data, oracle_bitmap=True)
Bitmap indexes cannot be unique and cannot be compressed. SQLAlchemy will not check for such limitations, only the database will.
Index compression¶
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)
Index(
"my_index",
my_table.c.data1,
my_table.c.data2,
unique=True,
oracle_compress=1,
)
The oracle_compress
parameter accepts either an integer specifying the
number of prefix columns to compress, or True
to use the default (all
columns for non-unique indexes, all but the last column for unique indexes).
Oracle Database Data Types¶
As with all SQLAlchemy dialects, all UPPERCASE types that are known to be valid
with Oracle Database are importable from the top level dialect, whether they
originate from sqlalchemy.types
or from the local dialect:
from sqlalchemy.dialects.oracle import (
BFILE,
BLOB,
CHAR,
CLOB,
DATE,
DOUBLE_PRECISION,
FLOAT,
INTERVAL,
LONG,
NCLOB,
NCHAR,
NUMBER,
NVARCHAR,
NVARCHAR2,
RAW,
TIMESTAMP,
VARCHAR,
VARCHAR2,
)
New in version 1.2.19: Added NCHAR
to the list of datatypes
exported by the Oracle dialect.
Types which are specific to Oracle Database, or have Oracle-specific construction arguments, are as follows:
Object Name | Description |
---|---|
Implement the Oracle |
|
Implement the Oracle |
|
Provide the Oracle Database DATE type. |
|
Oracle Database FLOAT. |
|
alias of |
|
Oracle Database ROWID type. |
|
Oracle Database implementation of |
- class sqlalchemy.dialects.oracle.BFILE¶
Members
Class signature
class
sqlalchemy.dialects.oracle.BFILE
(sqlalchemy.types.LargeBinary
)-
method
sqlalchemy.dialects.oracle.BFILE.
__init__(length: int | None = None)¶ inherited from the
sqlalchemy.types.LargeBinary.__init__
method ofLargeBinary
Construct a LargeBinary type.
- Parameters:
length¶ – optional, a length for the column for use in DDL statements, for those binary types that accept a length, such as the MySQL BLOB type.
-
method
- class sqlalchemy.dialects.oracle.BINARY_DOUBLE¶
Implement the Oracle
BINARY_DOUBLE
datatype.This datatype differs from the Oracle
DOUBLE
datatype in that it delivers a true 8-byte FP value. The datatype may be combined with a genericDouble
datatype usingTypeEngine.with_variant()
.See also
Members
Class signature
class
sqlalchemy.dialects.oracle.BINARY_DOUBLE
(sqlalchemy.types.Double
)-
method
sqlalchemy.dialects.oracle.BINARY_DOUBLE.
__init__(precision: int | None = None, asdecimal: bool = False, decimal_return_scale: int | None = None)¶ inherited from the
sqlalchemy.types.Float.__init__
method ofFloat
Construct a Float.
- Parameters:
precision¶ –
the numeric precision for use in DDL
CREATE TABLE
. Backends should attempt to ensure this precision indicates a number of digits for the genericFloat
datatype.Note
For the Oracle Database backend, the
Float.precision
parameter is not accepted when rendering DDL, as Oracle Database does not support float precision specified as a number of decimal places. Instead, use the Oracle Database-specificFLOAT
datatype and specify theFLOAT.binary_precision
parameter. This is new in version 2.0 of SQLAlchemy.To create a database agnostic
Float
that separately specifies binary precision for Oracle Database, useTypeEngine.with_variant()
as follows:from sqlalchemy import Column from sqlalchemy import Float from sqlalchemy.dialects import oracle Column( "float_data", Float(5).with_variant(oracle.FLOAT(binary_precision=16), "oracle"), )
asdecimal¶ – the same flag as that of
Numeric
, but defaults toFalse
. Note that setting this flag toTrue
results in floating point conversion.decimal_return_scale¶ – Default scale to use when converting from floats to Python decimals. Floating point values will typically be much longer due to decimal inaccuracy, and most floating point database types don’t have a notion of “scale”, so by default the float type looks for the first ten decimal places when converting. Specifying this value will override that length. Note that the MySQL float types, which do include “scale”, will use “scale” as the default for decimal_return_scale, if not otherwise specified.
-
method
- class sqlalchemy.dialects.oracle.BINARY_FLOAT¶
Implement the Oracle
BINARY_FLOAT
datatype.This datatype differs from the Oracle
FLOAT
datatype in that it delivers a true 4-byte FP value. The datatype may be combined with a genericFloat
datatype usingTypeEngine.with_variant()
.See also
Members
Class signature
class
sqlalchemy.dialects.oracle.BINARY_FLOAT
(sqlalchemy.types.Float
)-
method
sqlalchemy.dialects.oracle.BINARY_FLOAT.
__init__(precision: int | None = None, asdecimal: bool = False, decimal_return_scale: int | None = None)¶ inherited from the
sqlalchemy.types.Float.__init__
method ofFloat
Construct a Float.
- Parameters:
precision¶ –
the numeric precision for use in DDL
CREATE TABLE
. Backends should attempt to ensure this precision indicates a number of digits for the genericFloat
datatype.Note
For the Oracle Database backend, the
Float.precision
parameter is not accepted when rendering DDL, as Oracle Database does not support float precision specified as a number of decimal places. Instead, use the Oracle Database-specificFLOAT
datatype and specify theFLOAT.binary_precision
parameter. This is new in version 2.0 of SQLAlchemy.To create a database agnostic
Float
that separately specifies binary precision for Oracle Database, useTypeEngine.with_variant()
as follows:from sqlalchemy import Column from sqlalchemy import Float from sqlalchemy.dialects import oracle Column( "float_data", Float(5).with_variant(oracle.FLOAT(binary_precision=16), "oracle"), )
asdecimal¶ – the same flag as that of
Numeric
, but defaults toFalse
. Note that setting this flag toTrue
results in floating point conversion.decimal_return_scale¶ – Default scale to use when converting from floats to Python decimals. Floating point values will typically be much longer due to decimal inaccuracy, and most floating point database types don’t have a notion of “scale”, so by default the float type looks for the first ten decimal places when converting. Specifying this value will override that length. Note that the MySQL float types, which do include “scale”, will use “scale” as the default for decimal_return_scale, if not otherwise specified.
-
method
- class sqlalchemy.dialects.oracle.DATE¶
Provide the Oracle Database DATE type.
This type has no special Python behavior, except that it subclasses
DateTime
; this is to suit the fact that the Oracle DatabaseDATE
type supports a time value.Members
Class signature
class
sqlalchemy.dialects.oracle.DATE
(sqlalchemy.dialects.oracle.types._OracleDateLiteralRender
,sqlalchemy.types.DateTime
)-
method
sqlalchemy.dialects.oracle.DATE.
__init__(timezone: bool = False)¶ inherited from the
sqlalchemy.types.DateTime.__init__
method ofDateTime
Construct a new
DateTime
.- Parameters:
timezone¶ – boolean. Indicates that the datetime type should enable timezone support, if available on the base date/time-holding type only. It is recommended to make use of the
TIMESTAMP
datatype directly when using this flag, as some databases include separate generic date/time-holding types distinct from the timezone-capable TIMESTAMP datatype, such as Oracle Database.
-
method
- class sqlalchemy.dialects.oracle.FLOAT¶
Oracle Database FLOAT.
This is the same as
FLOAT
except that an Oracle Database -specificFLOAT.binary_precision
parameter is accepted, and theFloat.precision
parameter is not accepted.Oracle Database FLOAT types indicate precision in terms of “binary precision”, which defaults to 126. For a REAL type, the value is 63. This parameter does not cleanly map to a specific number of decimal places but is roughly equivalent to the desired number of decimal places divided by 0.3103.
New in version 2.0.
Members
Class signature
class
sqlalchemy.dialects.oracle.FLOAT
(sqlalchemy.types.FLOAT
)-
method
sqlalchemy.dialects.oracle.FLOAT.
__init__(binary_precision=None, asdecimal=False, decimal_return_scale=None)¶ Construct a FLOAT
- Parameters:
binary_precision¶ – Oracle Database binary precision value to be rendered in DDL. This may be approximated to the number of decimal characters using the formula “decimal precision = 0.30103 * binary precision”. The default value used by Oracle Database for FLOAT / DOUBLE PRECISION is 126.
asdecimal¶ – See
Float.asdecimal
decimal_return_scale¶ – See
Float.decimal_return_scale
-
method
- class sqlalchemy.dialects.oracle.INTERVAL¶
Members
Class signature
class
sqlalchemy.dialects.oracle.INTERVAL
(sqlalchemy.types.NativeForEmulated
,sqlalchemy.types._AbstractInterval
)-
method
sqlalchemy.dialects.oracle.INTERVAL.
__init__(day_precision=None, second_precision=None)¶ Construct an INTERVAL.
Note that only DAY TO SECOND intervals are currently supported. This is due to a lack of support for YEAR TO MONTH intervals within available DBAPIs.
-
method
- class sqlalchemy.dialects.oracle.NCLOB¶
Members
Class signature
class
sqlalchemy.dialects.oracle.NCLOB
(sqlalchemy.types.Text
)-
method
sqlalchemy.dialects.oracle.NCLOB.
__init__(length: int | None = None, collation: str | None = None)¶ inherited from the
sqlalchemy.types.String.__init__
method ofString
Create a string-holding type.
- Parameters:
length¶ – optional, a length for the column for use in DDL and CAST expressions. May be safely omitted if no
CREATE TABLE
will be issued. Certain databases may require alength
for use in DDL, and will raise an exception when theCREATE TABLE
DDL is issued if aVARCHAR
with no length is included. Whether the value is interpreted as bytes or characters is database specific.collation¶ –
Optional, a column-level collation for use in DDL and CAST expressions. Renders using the COLLATE keyword supported by SQLite, MySQL, and PostgreSQL. E.g.:
>>> from sqlalchemy import cast, select, String >>> print(select(cast("some string", String(collation="utf8"))))
SELECT CAST(:param_1 AS VARCHAR COLLATE utf8) AS anon_1Note
In most cases, the
Unicode
orUnicodeText
datatypes should be used for aColumn
that expects to store non-ascii data. These datatypes will ensure that the correct types are used on the database.
-
method
-
attribute
sqlalchemy.dialects.oracle..
sqlalchemy.dialects.oracle.NVARCHAR2¶ alias of
NVARCHAR
- class sqlalchemy.dialects.oracle.NUMBER¶
Class signature
class
sqlalchemy.dialects.oracle.NUMBER
(sqlalchemy.types.Numeric
,sqlalchemy.types.Integer
)
- class sqlalchemy.dialects.oracle.LONG¶
Members
Class signature
class
sqlalchemy.dialects.oracle.LONG
(sqlalchemy.types.Text
)-
method
sqlalchemy.dialects.oracle.LONG.
__init__(length: int | None = None, collation: str | None = None)¶ inherited from the
sqlalchemy.types.String.__init__
method ofString
Create a string-holding type.
- Parameters:
length¶ – optional, a length for the column for use in DDL and CAST expressions. May be safely omitted if no
CREATE TABLE
will be issued. Certain databases may require alength
for use in DDL, and will raise an exception when theCREATE TABLE
DDL is issued if aVARCHAR
with no length is included. Whether the value is interpreted as bytes or characters is database specific.collation¶ –
Optional, a column-level collation for use in DDL and CAST expressions. Renders using the COLLATE keyword supported by SQLite, MySQL, and PostgreSQL. E.g.:
>>> from sqlalchemy import cast, select, String >>> print(select(cast("some string", String(collation="utf8"))))
SELECT CAST(:param_1 AS VARCHAR COLLATE utf8) AS anon_1Note
In most cases, the
Unicode
orUnicodeText
datatypes should be used for aColumn
that expects to store non-ascii data. These datatypes will ensure that the correct types are used on the database.
-
method
- class sqlalchemy.dialects.oracle.RAW¶
Class signature
class
sqlalchemy.dialects.oracle.RAW
(sqlalchemy.types._Binary
)
- class sqlalchemy.dialects.oracle.ROWID¶
Oracle Database ROWID type.
When used in a cast() or similar, generates ROWID.
Class signature
class
sqlalchemy.dialects.oracle.ROWID
(sqlalchemy.types.TypeEngine
)
- class sqlalchemy.dialects.oracle.TIMESTAMP¶
Oracle Database implementation of
TIMESTAMP
, which supports additional Oracle Database-specific modesNew in version 2.0.
Members
Class signature
class
sqlalchemy.dialects.oracle.TIMESTAMP
(sqlalchemy.types.TIMESTAMP
)-
method
sqlalchemy.dialects.oracle.TIMESTAMP.
__init__(timezone: bool = False, local_timezone: bool = False)¶ Construct a new
TIMESTAMP
.
-
method
python-oracledb¶
Support for the Oracle Database database via the python-oracledb driver.
DBAPI¶
Documentation and download information (if applicable) for python-oracledb is available at: https://oracle.github.io/python-oracledb/
Connecting¶
Connect String:
oracle+oracledb://user:pass@hostname:port[/dbname][?service_name=<service>[&key=value&key=value...]]
Description¶
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.
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
create_engine()
withoracle+oracledb://...
will automatically select the sync version:from sqlalchemy import create_engine sync_engine = create_engine( "oracle+oracledb://scott:tiger@localhost?service_name=FREEPDB1" )
calling
create_async_engine()
withoracle+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=FREEPDB1" )
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=FREEPDB1" )
New in version 2.0.25: added support for the async version of oracledb.
Thick mode support¶
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 thick mode, call oracledb.init_oracle_client()
explicitly, or pass the parameter thick_mode=True
to
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",
"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.
See also
python-oracledb documentation 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 create_engine.connect_args
dictionary. See
python-oracledb documentation Oracle Net Services Connection Strings.
For example to use an Easy Connect string 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",
},
)
The Easy Connect syntax has been enhanced during the life of Oracle Database. Review the documentation for your database version. The current documentation is at Understanding the Easy Connect Naming Method.
The general syntax is similar to:
[[protocol:]//]host[:port][/[service_name]][?parameter_name=value{¶meter_name=value}]
Note that although the SQLAlchemy URL syntax hostname:port/dbname
looks
like Oracle’s Easy Connect syntax, it is different. SQLAlchemy’s URL requires a
system identifier (SID) for the dbname
component:
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
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
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
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. 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).
To take advantage of python-oracledb’s pool, use the
create_engine.creator
parameter to provide a function that
returns a new connection, along with setting
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")))
Refer to the python-oracledb documentation for oracledb.create_pool() for the arguments that can be used when creating a connection pool.
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. 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 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 toNone
, 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.Changed in version 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 LOB Datatypes.coerce_to_decimal
- see Precision Numerics for detail.encoding_errors
- see Encoding Errors for detail.
Unicode¶
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
Unicode
and 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 NCHAR
and
NCLOB
datatypes explicitly, or to pass the flag
use_nchar_for_unicode=True
to create_engine()
, which will cause
the SQLAlchemy dialect to use NCHAR/NCLOB for the Unicode
/
UnicodeText
datatypes instead of VARCHAR/CLOB.
Changed in version 1.3: The Unicode
and 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 create_engine()
is called.
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 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.
New in version 1.3.11.
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 Note that in some cases, significant performance degradation can occur when using these types vs. not.
On the SQLAlchemy side, the 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.
New in version 1.2.9: Added 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 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]
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 create_engine()
.
RETURNING Support¶
The oracledb dialect implements RETURNING using OUT parameters. The dialect supports RETURNING fully.
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 Connection.begin_twophase()
and
Session.twophase
for transparent ORM use.
Changed in version 2.0.32: added support for two phase transactions
Precision Numerics¶
SQLAlchemy’s numeric types can handle receiving and returning values as Python
Decimal
objects or float objects. When a Numeric
object, or a
subclass such as Float
, DOUBLE_PRECISION
etc. is in
use, the 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 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 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 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 Numeric
SQLAlchemy type (or a subclass of such).
Changed in version 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.
New in version 2.0.0: added support for the python-oracledb driver.
cx_Oracle¶
Support for the Oracle Database database via the cx-Oracle driver.
DBAPI¶
Documentation and download information (if applicable) for cx-Oracle is available at: https://oracle.github.io/python-cx_Oracle/
Connecting¶
Connect String:
oracle+cx_oracle://user:pass@hostname:port[/dbname][?service_name=<service>[&key=value&key=value...]]
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¶
cx_Oracle provides several methods of indicating the target database. The dialect translates from a series of different URL forms.
Hostname Connections with Easy Connect Syntax¶
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"
)
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.
To use a full Easy Connect string, pass it as the dsn
key value in a
create_engine.connect_args
dictionary:
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 =
(ADDRESS = (PROTOCOL = TCP)(HOST = mymachine.example.com)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = orclpdb1)
)
)
The cx_Oracle 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+cx_oracle://scott:tiger@myalias")
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.
SID Connections¶
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:port/dbname"
)
Above, the DSN passed to cx_Oracle is created by cx_Oracle.makedsn()
as
follows:
>>> import cx_Oracle
>>> 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 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"
)
Changed in version 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
create_engine.connect_args
parameter also accepts all
cx_Oracle DBAPI connect arguments.
To pass arguments directly to .connect()
without using the query
string, use the create_engine.connect_args
dictionary.
Any cx_Oracle parameter value and/or constant may be passed, such as:
import cx_Oracle
e = create_engine(
"oracle+cx_oracle://user:pass@dsn",
connect_args={
"encoding": "UTF-8",
"nencoding": "UTF-8",
"mode": cx_Oracle.SYSDBA,
"events": True,
},
)
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¶
There are also options that are consumed by the SQLAlchemy cx_oracle dialect
itself. These options are always passed directly to create_engine()
, such as:
e = create_engine(
"oracle+cx_oracle://user:pass@dsn", coerce_to_decimal=False
)
The parameters accepted by the cx_oracle dialect are as follows:
arraysize
- set the cx_oracle.arraysize value on cursors; defaults toNone
, 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.Changed in version 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 LOB Datatypes.coerce_to_decimal
- see Precision Numerics for detail.encoding_errors
- see Encoding Errors for detail.
Using cx_Oracle SessionPool¶
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
create_engine.creator
parameter to provide a function that
returns a new connection, along with setting
create_engine.pool_class
to NullPool
to disable
SQLAlchemy’s pooling:
import cx_Oracle
from sqlalchemy import create_engine
from sqlalchemy.pool import NullPool
pool = cx_Oracle.SessionPool(
user="scott",
password="tiger",
dsn="orclpdb",
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
)
The above engine may then be used normally where cx_Oracle’s pool handles connection pooling:
with engine.connect() as conn:
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.
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 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.
This can be achieved by wrapping pool.acquire()
:
import cx_Oracle
from sqlalchemy import create_engine
from sqlalchemy.pool import NullPool
pool = cx_Oracle.SessionPool(
user="scott",
password="tiger",
dsn="orclpdb",
min=2,
max=5,
increment=1,
threaded=True,
encoding="UTF-8",
nencoding="UTF-8",
)
def creator():
return pool.acquire(
cclass="MYCLASS", purity=cx_Oracle.ATTR_PURITY_SELF
)
engine = create_engine(
"oracle+cx_oracle://", creator=creator, poolclass=NullPool
)
The above engine may then be used normally where cx_Oracle handles session pooling and Oracle Database additionally uses DRCP:
with engine.connect() as conn:
print(conn.scalar("select 1 from dual"))
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 encoding configuration.
Ensuring the Correct Client Encoding¶
The long accepted standard for establishing client encoding for nearly all
Oracle Database related software is via the NLS_LANG 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 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@tnsalias?encoding=UTF-8&nencoding=UTF-8"
)
For the meaning of the encoding
and nencoding
parameters, please
consult
Characters Sets and National Language Support (NLS).
See also
Characters Sets and National Language Support (NLS) - in the cx_Oracle documentation.
Unicode-specific Column datatypes¶
The Core expression language handles unicode data by use of the
Unicode
and 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 Oracle Database is not configured with a Unicode character
set, the two options are to use the NCHAR
and
NCLOB
datatypes explicitly, or to pass the flag
use_nchar_for_unicode=True
to create_engine()
, which will cause
the SQLAlchemy dialect to use NCHAR/NCLOB for the Unicode
/
UnicodeText
datatypes instead of VARCHAR/CLOB.
Changed in version 1.3: The Unicode
and 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 create_engine()
is called.
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 function, and
is passed both via cx_Oracle’s encodingErrors
parameter consumed by
Cursor.var()
, as well as SQLAlchemy’s own decoding function, as the
cx_Oracle dialect makes use of both under different circumstances.
New in version 1.3.11.
Fine grained control over cx_Oracle data binding performance with setinputsizes¶
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
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 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
cx_Oracle’s list of built-in datatype symbols at
https://cx-oracle.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, in particular when specifying cx_Oracle.CLOB
.
On the SQLAlchemy side, the 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.
New in version 1.2.9: Added 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 BindParameter
objects which have a .key
and a .type
attribute:
from sqlalchemy import create_engine, event
engine = create_engine("oracle+cx_oracle://scott:tiger@host/xe")
@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¶
The CLOB
datatype in cx_Oracle incurs a significant performance overhead,
however is set by default for the Text
type within the SQLAlchemy 1.2
series. This setting can be modified as follows:
from sqlalchemy import create_engine, event
from cx_Oracle import CLOB
engine = create_engine("oracle+cx_oracle://scott:tiger@host/xe")
@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]
LOB Datatypes¶
LOB datatypes refer to the “large object” datatypes such as CLOB, NCLOB and 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 create_engine()
,
which takes place only engine-wide.
RETURNING Support¶
The cx_Oracle dialect implements RETURNING using OUT parameters. The dialect supports RETURNING fully.
Two Phase Transactions Not Supported¶
Two phase transactions are not supported under cx_Oracle due to poor driver support. The newer python-oracledb dialect however does support two phase transactions.
Precision Numerics¶
SQLAlchemy’s numeric types can handle receiving and returning values as Python
Decimal
objects or float objects. When a Numeric
object, or a
subclass such as Float
, DOUBLE_PRECISION
etc. is in
use, the 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 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 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 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
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 create_engine()
:
engine = create_engine("oracle+cx_oracle://dsn", 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 Numeric
SQLAlchemy type (or a subclass of such).
Changed in version 1.2: The numeric handling system for cx_Oracle has been reworked to take advantage of newer cx_Oracle features as well as better integration of outputtypehandlers.
flambé! the dragon and The Alchemist image designs created and generously donated by Rotem Yaari.
Created using Sphinx 7.2.6. Documentation last generated: Mon 13 Jan 2025 08:39:35 AM EST