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 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 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:
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
Changed in version 1.4: Added Identity
construct
in a Column
to specify the option of an autoincrementing
column.
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.
To set using per-connection execution options:
connection = engine.connect()
connection = 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.
Valid values for isolation_level
include:
READ COMMITTED
AUTOCOMMIT
SERIALIZABLE
The implementation for the
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.
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
installations.
The cx_Oracle dialect attempts 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.
See also
Setting Transaction Isolation Levels including DBAPI Autocommit
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.
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 Configuring 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
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
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
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",
max_identifier_length=30)
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",
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=128, it becomes:
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
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 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.
LIMIT/OFFSET/FETCH Support
Methods like Select.limit()
and 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 Select.fetch()
method.
Changed in version 2.0: the Oracle dialect now uses
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 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
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 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 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
to create_engine()
.
Changed in version 1.4: The Oracle 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.
See also
New “post compile” bound parameters used for LIMIT/OFFSET in Oracle, SQL Server.
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
support RETURNING with executemany statements). Multiple rows may be
returned as well.
Changed in version 2.0: the Oracle 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
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 8 Compatibility
Warning
The status of Oracle 8 compatibility is not known for SQLAlchemy
When Oracle 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. The NVARCHAR
and
NCLOB
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 dialect
knows 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 dialect 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 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
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
:
from sqlalchemy import create_engine, inspect
engine = create_engine("oracle+cx_oracle://s:t@dsn")
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 a UniqueConstraint
object, as Oracle
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);
the Table
will instead represent these using
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.
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+cx_oracle://scott:tiger@xe",
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 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 Table Options
The CREATE TABLE phrase supports the following options with Oracle
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, or ``True`` to use the default compression level.
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 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 Data Types
As with all SQLAlchemy dialects, all UPPERCASE types that are known to be
valid with Oracle 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, or have Oracle-specific
construction arguments, are as follows:
Object Name
Description
BFILE
BINARY_DOUBLE
BINARY_FLOAT
Provide the oracle DATE type.
FLOAT
Oracle FLOAT.
INTERVAL
NCLOB
NUMBER
NVARCHAR2
alias of NVARCHAR
ROWID
Oracle ROWID type.
TIMESTAMP
Oracle implementation of TIMESTAMP
, which supports additional
Oracle-specific modes
method sqlalchemy.dialects.oracle.BFILE.
__init__(length: int | None = None)
inherited from the sqlalchemy.types.LargeBinary.__init__
method of LargeBinary
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 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 of Float
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 generic
Float
datatype.
For the Oracle backend, the
Float.precision
parameter is not accepted
when rendering DDL, as Oracle does not support float precision
specified as a number of decimal places. Instead, use the
Oracle-specific FLOAT
datatype and specify the
FLOAT.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, use
TypeEngine.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 to False
. Note that setting this flag to True
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 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 of Float
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 generic
Float
datatype.
For the Oracle backend, the
Float.precision
parameter is not accepted
when rendering DDL, as Oracle does not support float precision
specified as a number of decimal places. Instead, use the
Oracle-specific FLOAT
datatype and specify the
FLOAT.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, use
TypeEngine.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 to False
. Note that setting this flag to True
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.
class sqlalchemy.dialects.oracle.DATE
Provide the oracle DATE type.
This type has no special Python behavior, except that it subclasses
DateTime
; this is to suit the fact that the Oracle
DATE
type supports a time value.
Members
__init__()
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 of DateTime
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.
class sqlalchemy.dialects.oracle.FLOAT
Oracle FLOAT.
This is the same as FLOAT
except that
an Oracle-specific FLOAT.binary_precision
parameter is accepted, and
the Float.precision
parameter is not accepted.
Oracle 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
__init__()
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 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 for FLOAT / DOUBLE PRECISION is 126.
asdecimal – See Float.asdecimal
decimal_return_scale – See
Float.decimal_return_scale
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.
Parameters:
day_precision – the day precision value. this is the number of
digits to store for the day field. Defaults to “2”
second_precision – the second precision value. this is the
number of digits to store for the fractional seconds field.
Defaults to “6”.
method sqlalchemy.dialects.oracle.NCLOB.
__init__(length: int | None = None, collation: str | None = None)
inherited from the sqlalchemy.types.String.__init__
method of String
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 a
length
for use in DDL, and will raise an exception when
the CREATE TABLE
DDL is issued if a VARCHAR
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_1
In most cases, the Unicode
or UnicodeText
datatypes should be used for a Column
that expects
to store non-ascii data. These datatypes will ensure that the
correct types are used on the database.
method sqlalchemy.dialects.oracle.LONG.
__init__(length: int | None = None,
collation: str | None = None)
inherited from the sqlalchemy.types.String.__init__
method of String
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 a
length
for use in DDL, and will raise an exception when
the CREATE TABLE
DDL is issued if a VARCHAR
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_1
In most cases, the Unicode
or UnicodeText
datatypes should be used for a Column
that expects
to store non-ascii data. These datatypes will ensure that the
correct types are used on the database.
class sqlalchemy.dialects.oracle.ROWID
Oracle 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 implementation of TIMESTAMP
, which supports additional
Oracle-specific modes
New in version 2.0.
Members
__init__()
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
.
Parameters:
timezone – boolean. Indicates that the TIMESTAMP type should
use Oracle’s TIMESTAMP WITH TIME ZONE
datatype.
local_timezone – boolean. Indicates that the TIMESTAMP type
should use Oracle’s TIMESTAMP WITH LOCAL TIME ZONE
datatype.
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...]]
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 Oracle Database, for
example from Oracle’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")
The full Easy Connect syntax
is not supported. Instead, use a tnsnames.ora
file and connect using a
Connections with tnsnames.ora or Oracle Cloud
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
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/?encoding=UTF-8&nencoding=UTF-8")
Users of Oracle Cloud should use this syntax and also configure the cloud
wallet as shown in cx_Oracle documentation Connecting to Autononmous Databases.
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:
engine = create_engine("oracle+cx_oracle://scott:tiger@hostname:1521/dbname?encoding=UTF-8&nencoding=UTF-8")
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)))'
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:
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 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
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
.
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 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 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=2, max=5, 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.
Using Oracle Database Resident Connection Pooling (DRCP)
When using Oracle’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 related software is via the NLS_LANG
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
.
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:
engine = create_engine("oracle+cx_oracle://scott:tiger@orclpdb/?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 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.
In the case that the 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 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 the 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 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]
RETURNING Support
The cx_Oracle dialect implements RETURNING using OUT parameters.
The dialect supports RETURNING fully.
LOB Datatypes
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.
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.
Two Phase Transactions Not Supported (use oracledb)
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 and should be preferred.
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, Oracle’s NUMBER
type can also
represent integer values if the “scale” is zero, so the Oracle-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 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.
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.
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 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.
See also
cx_Oracle - all of cx_Oracle’s notes apply to the oracledb driver
as well, with the exception that oracledb supports two phase transactions.
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()
with oracle+oracledb://...
will
automatically select the sync version, e.g.:
from sqlalchemy import create_engine
sync_engine = create_engine("oracle+oracledb://scott:tiger@localhost/?service_name=XEPDB1")
calling create_async_engine()
with
oracle+oracledb://...
will automatically select the async version,
e.g.:
from sqlalchemy.ext.asyncio import create_async_engine
asyncio_engine = create_async_engine("oracle+oracledb://scott:tiger@localhost/?service_name=XEPDB1")
The asyncio version of the dialect may also be specified explicitly using the
oracledb_async
suffix, as:
from sqlalchemy.ext.asyncio import create_async_engine
asyncio_engine = create_async_engine("oracle+oracledb_async://scott:tiger@localhost/?service_name=XEPDB1")
New in version 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.
To enable this mode, the user may call oracledb.init_oracle_client
manually, or by passing 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 to this parameter, as in:
engine = sa.create_engine("oracle+oracledb://...", thick_mode={
"lib_dir": "/path/to/oracle/client/lib", "driver_name": "my-app"
See also
https://python-oracledb.readthedocs.io/en/latest/api_manual/module.html#oracledb.init_oracle_client
Two Phase Transactions Supported
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
Connection.begin_twophase()
and Session.twophase
for transparent ORM use.
Changed in version 2.0.32: added support for two phase transactions
New in version 2.0.0: added support for oracledb driver.
flambé! the dragon and The Alchemist image designs created and generously donated by Rotem Yaari.
Created using Sphinx 7.2.6.
Documentation last generated: Sun 25 Aug 2024 06:08:56 PM EDT
Website content copyright © by SQLAlchemy authors and contributors.
SQLAlchemy and its documentation are licensed under the MIT license.
SQLAlchemy is a trademark of Michael Bayer. mike(&)zzzcomputing.com
All rights reserved.
Website generation by
zeekofile, with
huge thanks to the Blogofile
project.
Mastodon
Mastodon