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 表对象通常假定包含整数主键的表具有“自动递增”行为,意味着它们可以在插入时自动生成主键值。在 Oracle 数据库中,有两种可选方式可用,分别是使用 IDENTITY 列(仅适用于 Oracle 数据库 12 及以上版本)或将 SEQUENCE 与列关联。
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.
指定 GENERATED AS IDENTITY(Oracle Database 12 及以上版本)¶
Specifying GENERATED AS IDENTITY (Oracle Database 12 and above)
从版本 12 开始,Oracle 数据库可以使用 Identity
来指定自动递增行为,如下所示:
t = Table(
"mytable",
metadata,
Column("id", Integer, Identity(start=3), primary_key=True),
Column(...),
...,
)
上面 Table
对象的 CREATE TABLE 语句如下:
CREATE TABLE mytable (
id INTEGER GENERATED BY DEFAULT AS IDENTITY (START WITH 3),
...,
PRIMARY KEY (id)
)
Identity
对象支持多种选项来控制列的“自动递增”行为,例如起始值、递增值等。除了标准选项,Oracle 数据库还支持将 Identity.always
设置为 None
,以使用默认生成模式,这将在 DDL 中渲染为 GENERATED AS IDENTITY。Oracle 数据库还支持通过方言关键字参数指定两个自定义选项:
oracle_on_null
:设置为True
时,与 ‘BY DEFAULT’ 自动递增列一起渲染ON NULL
。oracle_order
:设置为True
时,渲染 ORDER 关键字,表示该自动递增列是有序的。对于使用 Oracle Real Application Clusters (RAC) 的环境,可能需要提供确定性排序。
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. Oracle
Database also supports two custom options specified using dialect kwargs:
oracle_on_null
: when set toTrue
rendersON NULL
in conjunction with a ‘BY DEFAULT’ identity column.oracle_order
: whenTrue
, renders the ORDER keyword, indicating the identity is definitively ordered. May be necessary to provide deterministic ordering using Oracle Real Application Clusters (RAC).
使用 SEQUENCE(所有 Oracle Database 版本)¶
Using a SEQUENCE (all Oracle Database versions)
Oracle 数据库的旧版本没有“自动递增”特性:SQLAlchemy 依赖序列来生成这些值。在较早版本的 Oracle 数据库中,必须明确指定序列以启用自动递增。这与大多数文档示例的假设(使用支持自动递增的数据库)有所不同。要指定序列,可以使用 sqlalchemy.schema.Sequence 对象并将其传递给 Column 构造函数:
t = Table(
"mytable",
metadata,
Column("id", Integer, Sequence("id_seq", start=1), primary_key=True),
Column(...),
...,
)
使用表反射时也需要进行此步骤,即 autoload_with=engine:
t = Table(
"mytable",
metadata,
Column("id", Integer, Sequence("id_seq", start=1), primary_key=True),
autoload_with=engine,
)
除了标准选项,Oracle 数据库还支持通过方言关键字参数指定以下自定义选项:
oracle_order
:设置为True
时,渲染 ORDER 关键字,表示该序列是有序的。对于使用 Oracle RAC 的环境,可能需要提供确定性排序。
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,
)
In addition to the standard options, Oracle Database supports the following custom option specified using dialect kwargs:
oracle_order
: whenTrue
, renders the ORDER keyword, indicating the sequence is definitively ordered. May be necessary to provide deterministic ordering using Oracle RAC.
事务隔离级别/自动提交¶
Transaction Isolation Level / Autocommit
Oracle 数据库支持“READ COMMITTED”和“SERIALIZABLE”隔离级别。AUTOCOMMIT 隔离级别也被 python-oracledb 和 cx_Oracle 方言支持。
可以通过每连接执行选项来设置隔离级别:
connection = engine.connect()
connection = connection.execution_options(isolation_level="AUTOCOMMIT")
对于 READ COMMITTED
和 SERIALIZABLE
,Oracle 数据库方言通过 ALTER SESSION
设置
会话级别的隔离级别,当连接返回连接池时会恢复为默认设置。
isolation_level
的有效值包括:
READ COMMITTED
AUTOCOMMIT
SERIALIZABLE
备注
由 Oracle 数据库方言实现的 Connection.get_isolation_level()
方法
必须强制开始事务,使用 Oracle 数据库 DBMS_TRANSACTION.LOCAL_TRANSACTION_ID 函数;
否则,通常无法读取任何隔离级别。
此外,若由于权限或其他原因无法访问 v$transaction
视图,
Connection.get_isolation_level()
方法将引发异常,
这在 Oracle 数据库安装中是常见的情况。
python-oracledb 和 cx_Oracle 方言会在方言首次连接数据库时调用
Connection.get_isolation_level()
方法,以获取“默认”的隔离级别。
该默认级别对于在通过 Connection.execution_options()
方法
临时修改后重置连接上的级别非常重要。若 Connection.get_isolation_level()
方法因 v$transaction
无法读取或其他数据库相关失败而引发异常,
则假定该级别为 “READ COMMITTED”。此初次连接时的条件不会发出警告,因为
这是 Oracle 数据库中常见的限制。
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
备注
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.
标识符大小写¶
Identifier Casing
在 Oracle 数据库中,数据字典使用大写字母表示所有不区分大小写的标识符名称。这与 SQLAlchemy 的预期相矛盾,SQLAlchemy 假设不区分大小写的名称表示为小写字母。
作为不区分大小写的标识符名称的示例,考虑以下表:
CREATE TABLE MyTable (Identifier INTEGER PRIMARY KEY)
如果你查询 Oracle 数据库关于此表的信息,表名将报告为 MYTABLE
,列名将报告为 IDENTIFIER
。与 PostgreSQL 和 MySQL 等大多数其他数据库相比,它们会将这些名称报告为 mytable
和 identifier
。这些名称 没有被引号引用,因此是不区分大小写的 。仅当它们在表定义中用引号括起来时,MyTable
和 Identifier
的特殊大小写才会被保留:
CREATE TABLE "MyTable" ("Identifier" INTEGER PRIMARY KEY)
在构建 SQLAlchemy Table
对象时, 所有小写的名称被视为不区分大小写 。因此,以下表假定名称不区分大小写:
Table("mytable", metadata, Column("identifier", Integer, primary_key=True))
而当使用混合大小写或大写名称时,假定名称是区分大小写的:
Table("MyTable", metadata, Column("Identifier", Integer, primary_key=True))
当发出文本 SQL SELECT 语句并查看 DBAPI cursor.description
属性中的列名时,数据库驱动程序层也会出现类似的情况。像 PostgreSQL 这样的数据库会将不区分大小写的名称标准化为小写:
>>> pg_engine = create_engine("postgresql://scott:tiger@localhost/test")
>>> pg_connection = pg_engine.connect()
>>> result = pg_connection.exec_driver_sql("SELECT 1 AS SomeName")
>>> result.cursor.description
(Column(name='somename', type_code=23),)
而 Oracle 会将其标准化为大写:
>>> oracle_engine = create_engine("oracle+oracledb://scott:tiger@oracle18c/xe")
>>> oracle_connection = oracle_engine.connect()
>>> result = oracle_connection.exec_driver_sql(
... "SELECT 1 AS SomeName FROM DUAL"
... )
>>> result.cursor.description
[('SOMENAME', <DbType DB_TYPE_NUMBER>, 127, None, 0, -127, True)]
为了实现表反射和仅文本 SQL 语句往返的跨数据库一致性,SQLAlchemy 在使用 Oracle 方言时执行一个步骤,称为 名称规范化。这个过程也可能适用于其他具有类似大写字母处理不区分大小写名称的第三方方言。
在使用名称规范化时,SQLAlchemy 会通过检查名称是否全部为大写字母来检测是否为不区分大小写的名称;如果是,它会假定这是一个不区分大小写的名称,并将其转换为小写名称。
对于表反射,在 Oracle 数据库的目录表中看到的全部大写的表名将被假定为不区分大小写的名称。这使得 Table
定义可以使用小写名称,并且在跨数据库视角下与 PostgreSQL 和 MySQL 等其他数据库兼容:
# 匹配使用 CREATE TABLE mytable 创建的表 Table(“mytable”, metadata, autoload_with=some_engine)
如上所示,所有小写的名称 "mytable"
是不区分大小写的;它将与 PostgreSQL 中报告的 "mytable"
和 Oracle 中报告的 "MYTABLE"
匹配。如果没有名称规范化,上述 Table
定义将无法在跨数据库的方式中进行自省,因为我们处理的是一个不区分大小写的名称,而不同的数据库报告该名称的方式不同。
在这种情况下,可以强制区分大小写,例如,如果我们想要表示带有精确大小写的引号表名 "MYTABLE"
,最简单的方式就是直接使用该大小写,这将被视为区分大小写的名称:
# 匹配使用 CREATE TABLE “MYTABLE” 创建的表 Table(“MYTABLE”, metadata, autoload_with=some_engine)
对于引号全部小写的名称的特殊情况,可以使用 quoted_name
构造函数:
from sqlalchemy import quoted_name
# 匹配使用 CREATE TABLE “mytable” 创建的表 Table(
quoted_name(“mytable”, quote=True), metadata, autoload_with=some_engine
)
名称规范化还适用于处理 纯文本 SQL 字符串 的结果集,这些 SQL 字符串没有其他 Table
或 Column
元数据与之关联。这包括使用 Connection.exec_driver_sql()
执行的 SQL 字符串和使用 text()
构造函数执行的 SQL 字符串,这些 SQL 字符串不包含 Column
元数据。
回到 Oracle 数据库的 SELECT 语句,尽管 cursor.description
报告列名为 SOMENAME
,SQLAlchemy 会将其名称规范化为 somename
:
>>> oracle_engine = create_engine("oracle+oracledb://scott:tiger@oracle18c/xe")
>>> oracle_connection = oracle_engine.connect()
>>> result = oracle_connection.exec_driver_sql(
... "SELECT 1 AS SomeName FROM DUAL"
... )
>>> result.cursor.description
[('SOMENAME', <DbType DB_TYPE_NUMBER>, 127, None, 0, -127, True)]
>>> result.keys()
RMKeyView(['somename'])
唯一的情况是,当使用全大写的引号名称时,上述行为会产生不准确的结果。SQLAlchemy 无法确定 cursor.description
中的某个特定名称是否为引号名称,因此无法判断它是否应当区分大小写,或是否应该进行名称规范化:
>>> result = oracle_connection.exec_driver_sql(
... 'SELECT 1 AS "SOMENAME" FROM DUAL'
... )
>>> result.cursor.description
[('SOMENAME', <DbType DB_TYPE_NUMBER>, 127, None, 0, -127, True)]
>>> result.keys()
RMKeyView(['somename'])
对于这个特殊的情况,SQLAlchemy 提供了 Connection.execution_options.driver_column_names
执行选项,它会关闭结果集的名称规范化:
>>> result = oracle_connection.exec_driver_sql(
... 'SELECT 1 AS "SOMENAME" FROM DUAL',
... execution_options={"driver_column_names": True},
... )
>>> result.keys()
RMKeyView(['SOMENAME'])
在 2.1 版本加入: 添加了 Connection.execution_options.driver_column_names
执行选项
In Oracle Database, the data dictionary represents all case insensitive identifier names using UPPERCASE text. This is in contradiction to the expectations of SQLAlchemy, which assume a case insensitive name is represented as lowercase text.
As an example of case insensitive identifier names, consider the following table:
CREATE TABLE MyTable (Identifier INTEGER PRIMARY KEY)
If you were to ask Oracle Database for information about this table, the
table name would be reported as MYTABLE
and the column name would
be reported as IDENTIFIER
. Compare to most other databases such as
PostgreSQL and MySQL which would report these names as mytable
and
identifier
. The names are not quoted, therefore are case insensitive.
The special casing of MyTable
and Identifier
would only be maintained
if they were quoted in the table definition:
CREATE TABLE "MyTable" ("Identifier" INTEGER PRIMARY KEY)
When constructing a SQLAlchemy Table
object, an all lowercase name
is considered to be case insensitive. So the following table assumes
case insensitive names:
Table("mytable", metadata, Column("identifier", Integer, primary_key=True))
Whereas when mixed case or UPPERCASE names are used, case sensitivity is assumed:
Table("MyTable", metadata, Column("Identifier", Integer, primary_key=True))
A similar situation occurs at the database driver level when emitting a
textual SQL SELECT statement and looking at column names in the DBAPI
cursor.description
attribute. A database like PostgreSQL will normalize
case insensitive names to be lowercase:
>>> pg_engine = create_engine("postgresql://scott:tiger@localhost/test")
>>> pg_connection = pg_engine.connect()
>>> result = pg_connection.exec_driver_sql("SELECT 1 AS SomeName")
>>> result.cursor.description
(Column(name='somename', type_code=23),)
Whereas Oracle normalizes them to UPPERCASE:
>>> oracle_engine = create_engine("oracle+oracledb://scott:tiger@oracle18c/xe")
>>> oracle_connection = oracle_engine.connect()
>>> result = oracle_connection.exec_driver_sql(
... "SELECT 1 AS SomeName FROM DUAL"
... )
>>> result.cursor.description
[('SOMENAME', <DbType DB_TYPE_NUMBER>, 127, None, 0, -127, True)]
In order to achieve cross-database parity for the two cases of a. table reflection and b. textual-only SQL statement round trips, SQLAlchemy performs a step called name normalization when using the Oracle dialect. This process may also apply to other third party dialects that have similar UPPERCASE handling of case insensitive names.
When using name normalization, SQLAlchemy attempts to detect if a name is case insensitive by checking if all characters are UPPERCASE letters only; if so, then it assumes this is a case insensitive name and is delivered as a lowercase name.
For table reflection, a tablename that is seen represented as all UPPERCASE
in Oracle Database’s catalog tables will be assumed to have a case insensitive
name. This is what allows the Table
definition to use lower case names
and be equally compatible from a reflection point of view on Oracle Database
and all other databases such as PostgreSQL and MySQL:
# matches a table created with CREATE TABLE mytable
Table("mytable", metadata, autoload_with=some_engine)
Above, the all lowercase name "mytable"
is case insensitive; it will match
a table reported by PostgreSQL as "mytable"
and a table reported by
Oracle as "MYTABLE"
. If name normalization were not present, it would
not be possible for the above Table
definition to be introspectable
in a cross-database way, since we are dealing with a case insensitive name
that is not reported by each database in the same way.
Case sensitivity can be forced on in this case, such as if we wanted to represent
the quoted tablename "MYTABLE"
with that exact casing, most simply by using
that casing directly, which will be seen as a case sensitive name:
# matches a table created with CREATE TABLE "MYTABLE"
Table("MYTABLE", metadata, autoload_with=some_engine)
For the unusual case of a quoted all-lowercase name, the quoted_name
construct may be used:
from sqlalchemy import quoted_name
# matches a table created with CREATE TABLE "mytable"
Table(
quoted_name("mytable", quote=True), metadata, autoload_with=some_engine
)
Name normalization also takes place when handling result sets from purely
textual SQL strings, that have no other Table
or Column
metadata associated with them. This includes SQL strings executed using
Connection.exec_driver_sql()
and SQL strings executed using the
text()
construct which do not include Column
metadata.
Returning to the Oracle Database SELECT statement, we see that even though
cursor.description
reports the column name as SOMENAME
, SQLAlchemy
name normalizes this to somename
:
>>> oracle_engine = create_engine("oracle+oracledb://scott:tiger@oracle18c/xe")
>>> oracle_connection = oracle_engine.connect()
>>> result = oracle_connection.exec_driver_sql(
... "SELECT 1 AS SomeName FROM DUAL"
... )
>>> result.cursor.description
[('SOMENAME', <DbType DB_TYPE_NUMBER>, 127, None, 0, -127, True)]
>>> result.keys()
RMKeyView(['somename'])
The single scenario where the above behavior produces inaccurate results
is when using an all-uppercase, quoted name. SQLAlchemy has no way to determine
that a particular name in cursor.description
was quoted, and is therefore
case sensitive, or was not quoted, and should be name normalized:
>>> result = oracle_connection.exec_driver_sql(
... 'SELECT 1 AS "SOMENAME" FROM DUAL'
... )
>>> result.cursor.description
[('SOMENAME', <DbType DB_TYPE_NUMBER>, 127, None, 0, -127, True)]
>>> result.keys()
RMKeyView(['somename'])
For this exact scenario, SQLAlchemy offers the Connection.execution_options.driver_column_names
execution options, which turns off name normalize for result sets:
>>> result = oracle_connection.exec_driver_sql(
... 'SELECT 1 AS "SOMENAME" FROM DUAL',
... execution_options={"driver_column_names": True},
... )
>>> result.keys()
RMKeyView(['SOMENAME'])
在 2.1 版本加入: Added the Connection.execution_options.driver_column_names
execution option
最大标识符长度¶
Maximum Identifier Lengths
SQLAlchemy 会注意到 Oracle 数据库支持的最大标识符长度。这会影响生成的 SQL 标签名称以及约束名称的生成,尤其是在使用 配置约束命名约定 中描述的约束命名约定特性时。
Oracle 数据库 12.2 将默认的最大标识符长度从 30 增加到 128。自 SQLAlchemy 1.4 起,Oracle 方言的默认最大标识符长度为 128 个字符。首次连接时,会获取数据库实际支持的最大长度。在所有情况下,设置 create_engine.max_identifier_length
参数会绕过此更改,所提供的值将直接使用:
- engine = create_engine(
“oracle+oracledb://scott:tiger@localhost:1521?service_name=freepdb1”, max_identifier_length=30,
)
如果未设置 create_engine.max_identifier_length
,oracledb 方言会在内部使用自 python-oracledb 2.5 版本以来在驱动程序连接上可用的 max_identifier_length
属性。当使用较旧的驱动程序版本或使用 cx_Oracle 方言时,SQLAlchemy 会尝试在首次连接时使用查询 SELECT value FROM v$parameter WHERE name = 'compatible'
来确定数据库的有效兼容版本。兼容版本是一个独立于实际数据库版本的版本号。它用于协助数据库迁移,并由 Oracle 数据库初始化参数配置。兼容版本随后确定数据库的最大标识符长度。如果无法访问 V$ 视图,则会改用数据库版本信息。
最大标识符长度在生成 SELECT 语句中的匿名 SQL 标签时也会发挥作用,但更关键的是在从命名约定生成约束名称时发挥作用。正是这一领域导致 SQLAlchemy 必须谨慎地更改此默认值。例如,以下命名约定会根据标识符长度生成两个非常不同的约束名称:
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))
当标识符长度为 30 时,以上 CREATE INDEX 看起来如下:
CREATE INDEX ix_some_column_name_1s_70cd ON t
(some_column_name_1, some_column_name_2, some_column_name_3)
然而,当长度为 128 时,它变成了:
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)
在 Oracle 数据库 12.2 或更高版本上运行 SQLAlchemy 1.4 之前的版本的应用程序因此可能面临数据库迁移场景,在这种场景下,想要“DROP CONSTRAINT”一个先前使用较短长度生成的名称。当标识符长度更改时,如果索引或约束的名称没有首先调整,这个迁移将失败。强烈建议这些应用程序使用 create_engine.max_identifier_length
来维护截断名称的生成控制,并在更改此值时在分阶段环境中充分审查和测试所有数据库迁移,以确保减轻此更改的影响。
在 1.4 版本发生变更: Oracle 数据库的默认 max_identifier_length 为 128 个字符,若 Oracle 数据库或其兼容性设置低于 12.2 版本,首次连接时会调整为 30。
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 配置约束命名约定 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.
在 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 支持¶
LIMIT/OFFSET/FETCH Support
像 Select.limit()
和 Select.offset()
这样的方法使用了 FETCH FIRST N ROW / OFFSET N ROWS
语法,假设使用的是 Oracle 数据库 12c 或更高版本,并且假设 SELECT 语句没有嵌套在联合语句(如 UNION)中。通过使用 Select.fetch()
方法,也可以直接使用这种语法。
在 2.0 版本发生变更: Oracle 数据库方言现在对所有 Select.limit()
和 Select.offset()
的使用,包括 ORM 和遗留的 Query
,都使用 FETCH FIRST N ROW / OFFSET N ROWS
。要强制使用旧版行为(使用窗口函数),请在 create_engine()
中指定 enable_offset_fetch=False
方言参数。
通过将 enable_offset_fetch=False
传递给 create_engine()
,可以禁用 FETCH FIRST / OFFSET
,从而强制使用基于窗口函数的“旧版”模式。对于 12c 之前的 Oracle 数据库版本,系统也会自动选择此模式。
在使用旧版模式时,或者当包含限制/偏移的 Select
语句嵌套在复合语句中时,会使用基于窗口函数的模拟方法来实现 LIMIT / OFFSET,这涉及到使用 ROW_NUMBER
创建子查询,这可能会导致性能问题以及复杂语句的 SQL 构造问题。然而,这种方法在所有 Oracle 数据库版本中都受到支持。请参阅下面的注释。
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.
在 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.
LIMIT/OFFSET 模拟注意事项(无法使用 fetch() 方法时)¶
Notes on LIMIT / OFFSET emulation (when fetch() method cannot be used)
如果在 Oracle 数据库 12c 之前的版本上使用 Select.limit()
和 Select.offset()
,或在 ORM 中使用 Query.limit()
和 Query.offset()
方法,以下注意事项适用:
SQLAlchemy 当前使用 ROWNUM 来实现 LIMIT/OFFSET;具体方法可以参考 https://blogs.oracle.com/oraclemagazine/on-rownum-and-limiting-results 。
默认情况下不会使用 “FIRST_ROWS()” 优化关键字。要启用此优化指令,请在
create_engine()
中指定optimize_limits=True
。在 1.4 版本发生变更: Oracle 数据库方言使用“后编译”方案呈现 limit/offset 整数值,在将语句传递给游标执行之前,直接呈现整数值。
use_binds_for_limits
标志不再生效。
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()
.在 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 支持¶
RETURNING Support
Oracle 数据库完全支持在 INSERT、UPDATE 和 DELETE 语句中使用 RETURNING,并且这些语句仅使用一组绑定参数(即 cursor.execute()
风格的语句;SQLAlchemy 通常不支持与 executemany 语句一起使用 RETURNING)。多个行也可以返回。
在 2.0 版本发生变更: Oracle 数据库后端对 RETURNING 的支持与其他后端保持一致。
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.
在 2.0 版本发生变更: the Oracle Database backend has full support for RETURNING on parity with other backends.
ON UPDATE CASCADE¶
ON UPDATE CASCADE
Oracle 数据库没有原生的 ON UPDATE CASCADE 功能。可以参考基于触发器的解决方案,地址为 https://web.archive.org/web/20090317041251/https://asktom.oracle.com/tkyte/update_cascade/index.html
在使用 SQLAlchemy ORM 时,ORM 具有有限的手动发出级联更新的能力 - 使用 “deferrable=True, initially=’deferred’” 关键字参数指定 ForeignKey 对象,并在每个 relationship() 上指定 “passive_updates=False”。
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 兼容性¶
Oracle Database 8 Compatibility
警告
不知道 Oracle 数据库 8 的兼容性状态在 SQLAlchemy 2.0 中的表现。
当检测到 Oracle 数据库 8 时,方言会自动配置为以下行为:
警告
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.
同义词/DBLINK 反射¶
Synonym/DBLINK Reflection
在使用反射与 Table 对象时,方言可以通过将 oracle_resolve_synonyms=True
作为关键字参数传递给 Table
构造函数,选择性地查找由同义词指示的表,无论是位于本地或远程模式中,还是通过 DBLINK 访问:
some_table = Table(
"some_table", autoload_with=some_engine, oracle_resolve_synonyms=True
)
设置此标志时,给定的名称(例如上面的 some_table
)不仅会在 ALL_TABLES
视图中查找,还会在 ALL_SYNONYMS
视图中查找,看看这个名称是否实际上是另一个名称的同义词。如果找到了同义词并且指向 DBLINK,Oracle 数据库方言会知道如何使用 DBLINK 语法(例如 @dblink
)来定位该表的信息。
oracle_resolve_synonyms
可以在接受反射参数的任何地方使用,包括 MetaData.reflect()
和 Inspector.get_columns()
等方法。
如果不使用同义词,应该禁用此标志。
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
Oracle 数据库方言可以返回关于外键、唯一约束、CHECK 约束以及表上索引的信息。
有关这些约束的原始信息可以通过以下方法获取:
Inspector.get_foreign_keys()
,
Inspector.get_unique_constraints()
,
Inspector.get_check_constraints()
,
Inspector.get_indexes()
。
在 Table
层级使用反射时,
Table
也将包括这些约束。
请注意以下几点:
使用
Inspector.get_check_constraints()
方法时, Oracle 数据库会为指定 “NOT NULL” 的列构建一个特殊的 “IS NOT NULL” 约束。 默认情况下,此约束 不会 返回;要包括 “IS NOT NULL” 约束,请传递include_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 )
在大多数情况下,当反射
Table
时,唯一约束* 不会* 作为UniqueConstraint
对象提供,因为 Oracle 数据库通常用 UNIQUE 索引来镜像唯一约束(例外情况似乎是当两个或更多的唯一约束表示相同的列时);因此,Table
将使用Index
并设置unique=True
标志来表示这些约束。Oracle 数据库会为表的主键创建一个隐式索引;该索引 会从所有索引结果中排除 。
反射时,索引列的列表不会包括以 SYS_NC 开头的列名。
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()
.
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.
SYSTEM/SYSAUX 表空间的表名¶
Table names with SYSTEM/SYSAUX tablespaces
Inspector.get_table_names()
和
Inspector.get_temp_table_names()
方法会返回当前引擎的表名列表。这些方法也是反射操作的一部分,例如在 MetaData.reflect()
中执行的操作。默认情况下,这些操作会排除 SYSTEM
和 SYSAUX
表空间。如果要更改此行为,可以使用 exclude_tablespaces
参数在引擎级别更改默认排除的表空间列表:
# 排除 SYSAUX 和 SOME_TABLESPACE,但不排除 SYSTEM
e = create_engine(
"oracle+oracledb://scott:tiger@localhost:1521/?service_name=freepdb1",
exclude_tablespaces=["SYSAUX", "SOME_TABLESPACE"],
)
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 支持和行为¶
FLOAT / DOUBLE Support and Behaviors
SQLAlchemy 的 Float
和 Double
数据类型是通用数据类型,会解析为给定后端的“最符合预期”的数据类型。
对于 Oracle 数据库,这意味着它们解析为 FLOAT
和 DOUBLE
类型:
>>> 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 的 FLOAT
/ DOUBLE
数据类型是 NUMBER
的别名。Oracle 数据库存储 NUMBER
值时具有完全精度,而不是浮动点精度,这意味着 FLOAT
/ DOUBLE
实际上并不表现得像原生的浮点数值。Oracle 数据库则提供了特殊的数据类型 BINARY_FLOAT
和 BINARY_DOUBLE
来提供真正的 4 字节和 8 字节浮点数值。
SQLAlchemy 通过 BINARY_FLOAT
和 BINARY_DOUBLE
直接支持这些数据类型。
要以数据库无关的方式使用 Float
或 Double
数据类型,同时允许 Oracle 后端使用其中之一,请使用 TypeEngine.with_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)
例如,在 Table
定义中使用此数据类型:
my_table = Table(
"my_table",
metadata,
Column(
"fp_data", Float().with_variant(oracle.BINARY_FLOAT(), "oracle")
),
)
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 兼容性¶
DateTime Compatibility
Oracle 数据库没有名为 DATETIME
的数据类型,只有 DATE
类型,它实际上可以存储日期和时间值。
因此,Oracle 数据库方言提供了一个类型 DATE
,它是 DateTime
的子类。此类型没有特殊行为,仅作为该类型的“标记”存在;此外,当数据库列被反射并且类型报告为 DATE
时,将使用支持时间的 DATE
类型。
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 数据库表选项¶
Oracle Database Table Options
在与 Table
构造结合使用时,CREATE TABLE 短语支持以下选项与 Oracle 数据库方言:
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)
oracle_compress
参数接受一个整数压缩级别,或者True
来使用默认压缩级别。TABLESPACE
:Table("mytable", metadata, ..., oracle_tablespace="EXAMPLE_TABLESPACE")
oracle_tablespace
参数指定表要创建的表空间。 当你希望在用户的默认表空间以外的表空间中创建表时,这非常有用。在 2.0.37 版本加入.
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.在 2.0.37 版本加入.
Oracle 数据库特定索引选项¶
Oracle Database Specific Index Options
位图索引¶
Bitmap Indexes
你可以指定 oracle_bitmap
参数来创建位图索引,而不是 B 树索引:
Index("my_index", my_table.c.data, oracle_bitmap=True)
位图索引不能是唯一的,也不能被压缩。SQLAlchemy 不会检查这些限制,只有数据库会检查。
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 数据库对包含大量重复值的索引有更高效的存储模式。使用 oracle_compress
参数启用键压缩:
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,
)
oracle_compress
参数接受一个整数,表示要压缩的前缀列的数量,或者 True
来使用默认值(对于非唯一索引压缩所有列,对于唯一索引压缩所有列但不包括最后一列)。
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 数据库数据类型¶
Oracle Database Data Types
与所有SQLAlchemy方言一样,所有已知对Oracle数据库有效的UPPERCASE类型都可以从顶级方言中导入,无论它们是来自 sqlalchemy.types
还是来自本地方言:
from sqlalchemy.dialects.oracle import (
BFILE,
BLOB,
CHAR,
CLOB,
DATE,
DOUBLE_PRECISION,
FLOAT,
INTERVAL,
LONG,
NCLOB,
NCHAR,
NUMBER,
NVARCHAR,
NVARCHAR2,
RAW,
TIMESTAMP,
VARCHAR,
VARCHAR2,
)
特定于Oracle数据库或具有Oracle特定构造参数的类型如下:
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,
)
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. |
|
|
|
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.
- 参数:
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()
.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.
- 参数:
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.备注
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()
.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.
- 参数:
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.备注
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
.- 参数:
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.
在 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
- 参数:
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.
- 参数:
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_1备注
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¶ 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.
- 参数:
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_1备注
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 modes在 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 是 Oracle 数据库的 Python 驱动程序。它默认采用 “thin” 客户端模式,无需任何依赖项,并支持可选的 “thick” 模式,该模式使用 Oracle 客户端库。它支持包括双阶段事务和 Asyncio 在内的 SQLAlchemy 功能。
Python-oracledb 是经过重命名和更新的 cx_Oracle 驱动程序。Oracle 不再在 cx_Oracle 命名空间中发布任何新版本。
SQLAlchemy 的 oracledb
方言在同一个方言名称下同时提供同步(sync)和异步(async)实现。实际使用哪种版本,取决于引擎的创建方式:
使用
oracle+oracledb://...
调用create_engine()
会自动选择同步版本:from sqlalchemy import create_engine sync_engine = create_engine( "oracle+oracledb://scott:tiger@localhost?service_name=FREEPDB1" )
使用
oracle+oracledb://...
调用create_async_engine()
会自动选择异步版本:from sqlalchemy.ext.asyncio import create_async_engine asyncio_engine = create_async_engine( "oracle+oracledb://scott:tiger@localhost?service_name=FREEPDB1" )
你也可以显式使用
oracledb_async
后缀来指定异步版本:from sqlalchemy.ext.asyncio import create_async_engine asyncio_engine = create_async_engine( "oracle+oracledb_async://scott:tiger@localhost?service_name=FREEPDB1" )
在 2.0.25 版本加入: 新增对 oracledb 异步版本的支持。
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" )
在 2.0.25 版本加入: added support for the async version of oracledb.
Thick模式支持¶
Thick mode support
默认情况下,python-oracledb 驱动以 “thin” 模式运行,无需安装 Oracle 客户端库。该驱动还支持使用 Oracle 客户端库的 “thick” 模式,以获取如 Oracle Application Continuity 等高级功能。
要启用 thick 模式,可显式调用 oracledb.init_oracle_client(),或在 create_engine()
中传入 thick_mode=True
。若需为 init_oracle_client()
传递自定义参数(如 lib_dir
路径),可以传入一个字典,例如:
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",
},
)
注意:仅在 macOS 或 Windows 上指定 lib_dir
路径。在 Linux 上其行为可能不会如预期。
参见
python-oracledb 文档 启用 python-oracledb Thick 模式
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.
参见
python-oracledb documentation Enabling python-oracledb Thick mode
连接到 Oracle 数据库¶
Connecting to Oracle Database
python-oracledb 提供了多种方式来指定目标数据库。该方言可以解析多种 URL 格式。
给定目标数据库的主机名、端口和服务名,可以使用 service_name
查询参数在 SQLAlchemy 中进行连接:
engine = create_engine(
"oracle+oracledb://scott:tiger@hostname:port?service_name=myservice"
)
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"
)
使用 Easy Connect 字符串连接¶
Connecting with Easy Connect strings
你也可以将任何有效的 python-oracledb 连接字符串作为 dsn
关键字的值,传入 create_engine.connect_args
字典中。参见 python-oracledb 文档
Oracle Net Services 连接字符串。
例如,若希望使用 Easy Connect 字符串,并设置连接超时为 30 秒(防止网络无法连接时卡顿),以及 60 秒的 keep-alive(避免空闲连接被防火墙终止):
e = create_engine(
"oracle+oracledb://@",
connect_args={
"user": "scott",
"password": "tiger",
"dsn": "hostname:port/myservice?transport_connect_timeout=30&expire_time=60",
},
)
Oracle 数据库在其发展过程中增强了 Easy Connect 语法。请查阅与你数据库版本匹配的文档。当前文档见 理解 Easy Connect 命名方法。
通用语法类似于:
[[protocol:]//]host[:port][/[service_name]][?parameter_name=value{¶meter_name=value}]
请注意,虽然 SQLAlchemy 的 URL 语法 hostname:port/dbname
看起来与 Oracle 的 Easy Connect 类似,但实际上它们是不同的。SQLAlchemy 的 URL 要求 dbname
组件是系统标识符(SID):
engine = create_engine("oracle+oracledb://scott:tiger@hostname:port/sid")
Easy Connect 语法不支持 SID。它使用服务名(service name),这是连接 Oracle 数据库的首选方式。
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.
传递 python-oracledb 连接参数¶
Passing python-oracledb connect arguments
其他 python-oracledb 驱动的 连接选项
可以通过 connect_args
传递。例如:
e = create_engine(
"oracle+oracledb://@",
connect_args={
"user": "scott",
"password": "tiger",
"dsn": "hostname:port/myservice",
"events": True,
"mode": oracledb.AUTH_MODE_SYSDBA,
},
)
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,
},
)
使用 tnsnames.ora TNS 别名连接¶
Connecting with tnsnames.ora TNS aliases
如果未提供端口、数据库名称或服务名,方言将使用 Oracle 数据库 DSN “连接字符串”。该方式会将 URL 中的 “hostname” 部分作为数据源名称。例如,如果 tnsnames.ora
文件中包含如下的 TNS 别名
myalias
:
myalias =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = mymachine.example.com)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = orclpdb1)
)
)
当 URL 中的 hostname 部分为 myalias
且未指定端口、数据库名或 service_name
时,python-oracledb 方言将连接到此数据库服务:
engine = create_engine("oracle+oracledb://scott:tiger@myalias")
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")
连接到 Oracle 自治数据库¶
Connecting to Oracle Autonomous Database
使用 Oracle Autonomous Database 的用户应使用上述 TNS 别名 URL,或将 TNS 别名作为 dsn
键值传入
create_engine.connect_args
字典中。
如果 Oracle Autonomous Database 配置为使用双向 TLS(”mTLS”)连接,则需要额外配置,详见 连接到 Oracle Cloud Autonomous Databases。简而言之,Thick 模式的用户应配置文件路径,并在 sqlnet.ora
中正确设置钱包路径:
e = create_engine(
"oracle+oracledb://@",
thick_mode={
# 包含 tnsnames.ora 和 cwallet.so 的目录
"config_dir": "/opt/oracle/wallet_dir",
},
connect_args={
"user": "scott",
"password": "tiger",
"dsn": "mydb_high",
},
)
Thin 模式下的 mTLS 用户应在创建引擎时提供相应目录和 PEM 钱包密码,示例如下:
e = create_engine(
"oracle+oracledb://@",
connect_args={
"user": "scott",
"password": "tiger",
"dsn": "mydb_high",
"config_dir": "/opt/oracle/wallet_dir", # 包含 tnsnames.ora 的目录
"wallet_location": "/opt/oracle/wallet_dir", # 包含 ewallet.pem 的目录
"wallet_password": "top secret", # PEM 文件的密码
},
)
通常情况下,config_dir
和 wallet_location
是同一个目录,即解压 Oracle Autonomous Database 钱包 zip 文件的路径。请注意应保护该目录。
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
具有多个并发用户的应用应使用连接池。对于长时间运行但不频繁使用连接的单用户应用,使用最小连接池也会带来好处。
python-oracledb 驱动提供了自身的连接池实现,可替代 SQLAlchemy 的连接池功能。该连接池支持高可用特性,如死连接检测、计划内数据库停机时的连接抽取(draining)、Oracle Application Continuity 和 Transparent Application Continuity,以及对 Database Resident Connection Pooling(DRCP) 的支持。
要使用 python-oracledb 的连接池,可通过 create_engine.creator
参数传入一个返回新连接的函数,并将
create_engine.pool_class
设置为 NullPool
,以禁用 SQLAlchemy 自带的连接池:
import oracledb
from sqlalchemy import create_engine
from sqlalchemy import text
from sqlalchemy.pool import NullPool
# 取消注释以启用可选的 python-oracledb Thick 模式。
# 请参考 python-oracledb 文档,使用合适的参数
# 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
)
之后可正常使用该引擎。连接池将在内部由 python-oracledb 管理:
with engine.connect() as conn:
print(conn.scalar(text("select 1 from dual")))
有关创建连接池时可用参数,请参阅 python-oracledb 文档中 oracledb.create_pool() 的说明。
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.
使用 Oracle 数据库驻留连接池 (DRCP)¶
Using Oracle Database Resident Connection Pooling (DRCP)
使用 Oracle 数据库的 Database Resident Connection Pooling(DRCP)时,最佳实践是指定连接类(connection class)和 “purity”。参见 python-oracledb 的 DRCP 文档。示例如下:
import oracledb
from sqlalchemy import create_engine
from sqlalchemy import text
from sqlalchemy.pool import NullPool
# 取消注释以启用可选的 python-oracledb Thick 模式。
# 请参考 python-oracledb 文档,使用合适的参数
# 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
)
之后即可正常使用该引擎,python-oracledb 管理应用连接池,Oracle 数据库使用 DRCP:
with engine.connect() as conn:
print(conn.scalar(text("select 1 from dual")))
如果希望为不同连接使用不同的连接类或 purity,可封装 pool.acquire()
:
import oracledb
from sqlalchemy import create_engine
from sqlalchemy import text
from sqlalchemy.pool import NullPool
# 取消注释以启用 python-oracledb Thick 模式。
# 请参考 python-oracledb 文档,使用合适的参数
# 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
)
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
)
驱动程序外部 SQLAlchemy oracledb 方言使用的引擎选项¶
Engine Options consumed by the SQLAlchemy oracledb dialect outside of the driver
SQLAlchemy 的 oracledb 方言还支持一些由自身消费的选项。这些选项始终通过 create_engine()
直接传入,例如:
e = create_engine("oracle+oracledb://user:pass@tnsalias", arraysize=500)
oracledb 方言所支持的参数如下:
arraysize
- 设置驱动的 cursor.arraysize 值。默认为None
,表示使用驱动的默认值 100。
此设置控制在获取行时缓冲的行数,若在返回大量数据的查询中调高此值,可能会显著提升性能。
在 2.0.26 版本发生变更: - 默认值由 50 更改为 None,以使用驱动自身的默认值。
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.在 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 数据类型.coerce_to_decimal
- see 精度数值 for detail.encoding_errors
- see 编码错误 for detail.
Unicode¶
Unicode
在 Python 3 下,所有 DBAPI 都以 Unicode 字符串为基础,字符串天然为 Unicode 类型。
As is the case for all DBAPIs under Python 3, all strings are inherently Unicode strings.
确保客户端编码正确¶
Ensuring the Correct Client Encoding
在 python-oracledb 中,用于所有字符数据的编码为 “UTF-8”。
In python-oracledb, the encoding used for all character data is “UTF-8”.
Unicode 特定的列数据类型¶
Unicode-specific Column datatypes
Core 表达式语言通过使用 Unicode
与 UnicodeText
数据类型来处理 Unicode 数据。
默认情况下,这些类型分别对应于 Oracle 数据库的 VARCHAR2 和 CLOB 类型。
当使用这些类型处理 Unicode 数据时,预期数据库应配置为支持 Unicode 的字符集,
以便 VARCHAR2 和 CLOB 类型可以正确容纳数据。
若 Oracle 数据库未配置为 Unicode 字符集,有两种替代方式:一是显式使用 NCHAR
和
NCLOB
数据类型,二是向 create_engine()
传入参数 use_nchar_for_unicode=True
,
此时 SQLAlchemy 方言将在使用 Unicode
/ UnicodeText
数据类型时,自动改用 NCHAR/NCLOB,而非默认的 VARCHAR/CLOB。
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.
编码错误¶
Encoding Errors
在较为少见的场景中,若 Oracle 数据库中的数据编码存在异常,方言提供了 encoding_errors
参数以控制 Unicode 解码时的错误处理行为。
该参数的值将传入 Python 的 decode 函数,
并同时通过 python-oracledb 的 encodingErrors
参数传递给 Cursor.var()
,
以及传递给 SQLAlchemy 自身的解码函数,因为 oracledb 方言在不同场景下可能会使用其中任意一个。
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.
使用 setinputsizes 对 python-oracledb 数据绑定进行细粒度控制¶
Fine grained control over python-oracledb data binding with setinputsizes
python-oracledb DBAPI 在设计上高度依赖 DBAPI 的 setinputsizes()
调用。
该调用的作用是为即将绑定到 SQL 语句的 Python 参数设定相应的数据库数据类型。
虽然几乎所有其他 DBAPI 都很少或根本不使用 setinputsizes()
,但 python-oracledb 的实现对此调用极为依赖,
并且在某些场景下,SQLAlchemy 无法自动准确地判断应该如何绑定数据。
部分设置可能会对性能产生显著影响,同时也会改变类型转换行为。
强烈建议 oracledb 方言的用户阅读 python-oracledb 所提供的 数据库类型符号列表。 请注意,在某些情况下,使用这些类型可能会引发明显的性能下降。
在 SQLAlchemy 一侧,可以使用 DialectEvents.do_setinputsizes()
事件来实现对 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.
示例 1 - 记录所有 setinputsizes 调用¶
Example 1 - logging all setinputsizes calls
下列示例展示了如何从 SQLAlchemy 的角度记录在转换为原始 setinputsizes()
参数字典之前的中间值。该字典的键是 BindParameter
对象,每个对象具有 .key
和 .type
属性:
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,
)
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,
)
示例 2 - 移除所有与 CLOB 的绑定¶
Example 2 - remove all bindings to CLOB
出于性能考虑,SQLAlchemy 默认将 Oracle 数据库中的 Text
类型映射为 LOB 类型。该行为可如下修改:
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]
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 数据类型¶
LOB Datatypes
LOB 数据类型指的是“大对象”类型,如 CLOB、NCLOB 和 BLOB。Oracle 数据库可以高效地将这些类型作为单一缓冲区返回。SQLAlchemy 默认使用类型处理器(type handler)来完成此行为。
若要禁用类型处理器并将 LOB 对象作为传统的带 read()
方法的缓冲对象返回,可在调用 create_engine()
时传入参数 auto_convert_lobs=False
。
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
oracledb 方言通过 OUT 参数实现了 RETURNING 功能,方言完全支持 RETURNING 子句。
The oracledb dialect implements RETURNING using OUT parameters. The dialect supports RETURNING fully.
两阶段事务支持¶
Two Phase Transaction Support
python-oracledb 完全支持两阶段事务(Thin 模式需 python-oracledb 2.3 及以上版本)。相关 API 可在 Core 层通过 Connection.begin_twophase()
提供,
也可通过 Session.twophase
供 ORM 层透明使用。
在 2.0.32 版本发生变更: 增加对两阶段事务的支持
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.
在 2.0.32 版本发生变更: added support for two phase transactions
精度数值¶
Precision Numerics
SQLAlchemy 的数值类型可以以 Python 的 Decimal
对象或 float 对象的形式接收和返回数据。当使用 Numeric
类型或其子类(如 Float
、DOUBLE_PRECISION
等)时,
Numeric.asdecimal
标志决定了是否将返回值强制转换为 Decimal
,或以 float 对象返回。
在 Oracle 数据库中,这一处理更为复杂,因为 NUMBER
类型在 “scale” 为零时也可以表示整数。
为此,Oracle 特定的 NUMBER
类型也考虑到了此特性。
oracledb 方言广泛使用连接级与游标级的 “outputtypehandler” 可调用对象,以按需对数值类型进行强制转换。
这些处理器针对当前使用的 Numeric
类型的具体形式,也可用于不带 SQLAlchemy 类型对象的场景。
已观察到某些场景下 Oracle 数据库返回的数值类型信息可能不完整或模糊,例如在多层子查询中嵌套的数值类型。
类型处理器在所有场景下都尽力做出合理判断,在可能的情况下委托底层 python-oracledb DBAPI 做最终决定。
当未使用任何类型对象(例如执行原始 SQL 字符串)时,将启用默认的 “outputtypehandler”,其通常会将指定了精度和小数位的数值以 Python 的 Decimal
对象返回。
若因性能考虑希望禁用这种 Decimal 强制转换行为,可传入参数 coerce_to_decimal=False
给 create_engine()
:
engine = create_engine(
"oracle+oracledb://scott:tiger@tnsalias", coerce_to_decimal=False
)
coerce_to_decimal
标志仅影响那些未与 Numeric
类型(或其子类)相关联的原始字符串 SQL 语句的返回结果。
在 2.0.0 版本加入: 添加对 python-oracledb 驱动的支持。
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).
在 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 是 Oracle 数据库的原始驱动程序。它已被 python-oracledb 取代,应改用后者。
cx_Oracle was the original driver for Oracle Database. It was superseded by python-oracledb which should be used instead.
DSN 与主机名连接¶
DSN vs. Hostname connections
cx_Oracle 提供了几种指示目标数据库的方法。方言由一系列不同的 URL 形式翻译而来。
cx_Oracle provides several methods of indicating the target database. The dialect translates from a series of different URL forms.
使用 Easy Connect 语法的主机名连接¶
Hostname Connections with Easy Connect Syntax
给定目标数据库的主机名、端口和服务名,例如使用 Oracle Database 的 Easy Connect 语法时,可通过 service_name
查询字符串参数在 SQLAlchemy 中建立连接:
engine = create_engine(
"oracle+cx_oracle://scott:tiger@hostname:port?service_name=myservice&encoding=UTF-8&nencoding=UTF-8"
)
注意:在 cx_Oracle 8.0 中,默认的编码参数 encoding
和 nencoding
被修改为 “UTF-8”,因此在使用该版本或更高版本时可以省略这些参数。
若要使用完整的 Easy Connect 字符串,可通过 create_engine.connect_args
字典传入 dsn
键值:
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",
},
)
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",
},
)
使用 tnsnames.ora 或 Oracle 自治数据库的连接¶
Connections with tnsnames.ora or to Oracle Autonomous Database
另外,如果未提供端口、数据库名或服务名,方言将使用 Oracle Database 的 DSN “连接字符串”。此时,URL 中的主机名部分会作为数据源名称。例如,若 tnsnames.ora
文件中包含以下名为 myalias
的 TNS 别名:
myalias =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = mymachine.example.com)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = orclpdb1)
)
)
当 URL 中的主机名为 myalias
,并且未指定端口、数据库名或 service_name
时,cx_Oracle 方言将连接到上述数据库服务:
engine = create_engine("oracle+cx_oracle://scott:tiger@myalias")
使用 Oracle Autonomous Database 的用户应采用此语法。若数据库配置为使用双向 TLS(“mTLS”),还需按照 cx_Oracle 文档中 连接到 Autonomous 数据库 的示例配置 cloud wallet。
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 连接¶
SID Connections
如需使用 Oracle 数据库已弃用的 System Identifier(SID)连接语法,可将 SID 作为 URL 中的“数据库名”部分传入:
engine = create_engine(
"oracle+cx_oracle://scott:tiger@hostname:port/dbname"
)
上例中传入 cx_Oracle 的 DSN 是通过 cx_Oracle.makedsn()
创建的,如下所示:
>>> import cx_Oracle
>>> cx_Oracle.makedsn("hostname", 1521, sid="dbname")
'(DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=hostname)(PORT=1521))(CONNECT_DATA=(SID=dbname)))'
注意:虽然 SQLAlchemy 的 hostname:port/dbname
语法看起来类似于 Oracle 的 Easy Connect 语法,但它是不同的。
此语法使用 SID 代替 Easy Connect 所需的 service name。Easy Connect 不支持 SID。
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.
传递 cx_Oracle 连接参数¶
Passing cx_Oracle connect arguments
其他连接参数通常可通过 URL 查询字符串传入;某些特殊符号如 SYSDBA
会被自动拦截并转换为正确的常量:
e = create_engine(
"oracle+cx_oracle://user:pass@dsn?encoding=UTF-8&nencoding=UTF-8&mode=SYSDBA&events=true"
)
若要绕过查询字符串、直接将参数传入 .connect()
,可使用 create_engine.connect_args
字典。可传入任意 cx_Oracle 参数值和/或常量,例如:
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,
},
)
注意:在 cx_Oracle 8.0 中,默认的 encoding
和 nencoding
已被修改为 “UTF-8”,因此在该版本或之后版本中可以省略这些参数。
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"
)
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.
驱动程序外部 SQLAlchemy cx_Oracle 方言使用的选项¶
Options consumed by the SQLAlchemy cx_Oracle dialect outside of the driver
也可以通过传递额外选项给 create_engine()
来设置由 SQLAlchemy cx_oracle 方言自身消费的参数,例如:
e = create_engine(
"oracle+cx_oracle://user:pass@dsn", coerce_to_decimal=False
)
cx_oracle 方言接受以下参数:
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.
在 2.0.26 版本发生变更: - changed the default value from 50 to None, to use the default value of the driver itself.
使用 cx_Oracle 会话池¶
Using cx_Oracle SessionPool
cx_Oracle 驱动程序提供了自己的连接池实现,可替代 SQLAlchemy 的连接池机制。该连接池支持 Oracle 数据库的高级特性,例如死连接检测、计划性停机时的连接排空、对 Oracle Application Continuity 与 Transparent Application Continuity 的支持,以及对数据库驻留连接池(DRCP)的支持。
要使用驱动自带的连接池,可通过 create_engine.creator
参数传入一个返回新连接的函数,同时设置 create_engine.pool_class
为 NullPool
,以禁用 SQLAlchemy 的连接池:
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
)
上述引擎可正常使用,由 cx_Oracle 的连接池管理实际的连接:
with engine.connect() as conn:
print(conn.scalar("select 1 from dual"))
除了为多用户应用程序提供可扩展性外,cx_Oracle 的会话池还支持 Oracle 的特性,如 DRCP 与 Application Continuity。
注意:连接池的创建参数 threaded
、 encoding
和 nencoding
在 cx_Oracle 的后续版本中已被弃用。
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.
使用 Oracle 数据库驻留连接池 (DRCP)¶
Using Oracle Database Resident Connection Pooling (DRCP)
在使用 Oracle 数据库的 DRCP(Database Resident Connection Pooling)时,最佳实践是在从 SessionPool 获取连接时传递连接类(connection class)和“纯度(purity)”。参考 cx_Oracle DRCP 文档。
这可以通过封装 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
)
上述 engine 可以像平常一样使用,此时由 cx_Oracle 处理会话池,同时 Oracle 数据库会使用 DRCP:
with engine.connect() as conn:
print(conn.scalar("select 1 from dual"))
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¶
Unicode
如同所有 Python 3 下的 DBAPI,一切字符串本质上都是 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
长期以来,被广泛接受的设置 Oracle 数据库客户端编码的标准方式是通过环境变量 NLS_LANG。早期版本的 cx_Oracle 使用该环境变量作为编码配置来源。该变量的格式为 Territory_Country.CharacterSet,典型的值是 AMERICAN_AMERICA.AL32UTF8
。自 cx_Oracle 8 起默认使用字符集 “UTF-8”,并忽略 NLS_LANG 中的字符集部分。
cx_Oracle 驱动还支持以编程方式指定编码,即通过将 encoding
和 nencoding
参数直接传递给其 .connect()
函数。这些参数也可以在 URL 中指定:
engine = create_engine(
"oracle+cx_oracle://scott:tiger@tnsalias?encoding=UTF-8&nencoding=UTF-8"
)
关于 encoding
和 nencoding
参数的含义,请参考:
字符集与国家语言支持(NLS)。
参见
字符集与国家语言支持(NLS) - cx_Oracle 文档中关于 NLS 的说明。
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).
参见
Characters Sets and National Language Support (NLS) - in the cx_Oracle documentation.
Unicode 特定的列数据类型¶
Unicode-specific Column datatypes
Core 表达式语言通过 Unicode
与 UnicodeText
数据类型来处理 Unicode 数据。这些类型默认对应 Oracle 数据库的 VARCHAR2 和 CLOB 类型。使用这些类型时,建议数据库配置为支持 Unicode 的字符集,并设置合适的 NLS_LANG
环境变量(适用于较旧版本的 cx_Oracle),以便 VARCHAR2 和 CLOB 能够正确存储 Unicode 数据。
如果 Oracle 数据库未配置为 Unicode 字符集,有两个替代方案:显式使用 NCHAR
和 NCLOB
数据类型,或在调用 create_engine()
时传入 use_nchar_for_unicode=True
参数,此设置将使 SQLAlchemy 方言在处理 Unicode
/ UnicodeText
类型时使用 NCHAR/NCLOB 类型替代 VARCHAR/CLOB。
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.
编码错误¶
Encoding Errors
若数据库中存在编码损坏的数据,方言还接受一个 encoding_errors
参数,用以传递给 Unicode 解码函数,从而控制解码错误的处理方式。该值最终被传递给 Python 的 decode 函数,并通过 cx_Oracle 的 encodingErrors
参数被 Cursor.var()
使用,同时 SQLAlchemy 本身的解码函数也会使用该参数,因为 cx_Oracle 方言在不同场景下会采用不同的解码方式。
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.
使用 setinputsizes 对 cx_Oracle 数据绑定性能进行细粒度控制¶
Fine grained control over cx_Oracle data binding performance with setinputsizes
cx_Oracle DBAPI 对 DBAPI 的 setinputsizes()
调用具有深层且根本性的依赖。该调用的目的是为传递给 SQL 语句的 Python 参数绑定数据类型。几乎没有其他 DBAPI 使用此调用,但 cx_Oracle DBAPI 在与 Oracle 数据库客户端接口交互时高度依赖此机制。在某些场景下,SQLAlchemy 无法准确获知如何绑定数据,因为某些设置可能会对性能产生重大影响,同时还会改变类型转换行为。
强烈建议 使用 cx_Oracle 方言的用户阅读 cx_Oracle 提供的内建数据类型符号列表:
https://cx-oracle.readthedocs.io/en/latest/api_manual/module.html#database-types。
请注意,在某些情况下,使用这些类型(如 cx_Oracle.CLOB
)可能会导致显著的性能下降。
在 SQLAlchemy 端,可以使用 DialectEvents.do_setinputsizes()
事件实现运行时的可视化(如记录日志)或对 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.
示例 1 - 记录所有 setinputsizes 调用¶
Example 1 - logging all setinputsizes calls
下面的示例展示了如何从 SQLAlchemy 的角度记录中间值,即这些值在被转换为原始 setinputsizes()
参数字典之前的状态。该字典的键是 BindParameter
对象,它们具有 .key
和 .type
属性:
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(
"绑定参数名: %s SQLAlchemy 类型: %r DBAPI 对象: %s",
bindparam.key,
bindparam.type,
dbapitype,
)
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,
)
示例 2 - 移除所有与 CLOB 的绑定¶
Example 2 - remove all bindings to CLOB
在 cx_Oracle 中,CLOB
数据类型会带来显著的性能开销,然而在 SQLAlchemy 1.2 系列中,它是 Text
类型的默认设置。这个设置可以如下方式修改:
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]
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 数据类型¶
LOB Datatypes
LOB 数据类型是指像 CLOB、NCLOB 和 BLOB 这样的“大对象”类型。现代版本的 cx_Oracle 针对这些数据类型进行了优化,可以将其作为单个缓冲区传递。因此,SQLAlchemy 默认使用这些较新的类型处理器。
若要禁用这些新的类型处理器,并将 LOB 对象作为传统的带 read()
方法的缓冲对象传递,可以在调用 create_engine()
时传入参数 auto_convert_lobs=False
。此设置仅在引擎级别生效。
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 支持¶
RETURNING Support
cx_Oracle 方言通过 OUT 参数实现了 RETURNING 子句的支持。该方言对 RETURNING 的支持是完整的。
The cx_Oracle dialect implements RETURNING using OUT parameters. The dialect supports RETURNING fully.
不支持两阶段事务¶
Two Phase Transactions Not Supported
由于驱动支持不佳,cx_Oracle 不支持两阶段事务。相比之下,较新的 python-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.
精度数值¶
Precision Numerics
SQLAlchemy 的数值类型可以处理将值作为 Python 的 Decimal
对象或浮点数返回和接收。当使用 Numeric
对象或其子类(如 Float
、DOUBLE_PRECISION
等)时,Numeric.asdecimal
标志用于决定返回值是强制转换为 Decimal
,还是保留为浮点数。
在 Oracle 数据库中,情况更复杂一些,因为 NUMBER
类型也可能表示整数值(当其小数位为 0 时)。因此,Oracle 特定的 NUMBER
类型会将此情况考虑在内。
cx_Oracle 方言广泛使用连接级和游标级的 “outputtypehandler” 回调函数,以按需转换数值类型。这些回调函数会根据使用的 Numeric
变体不同而定,也适用于不使用 SQLAlchemy 类型对象的情况。有时 Oracle 数据库返回的数值类型信息可能不完整或模糊,例如数值类型被嵌套在多层子查询中。类型处理器尽最大努力做出正确判断,并在所有情况下委托底层 cx_Oracle DBAPI 做最终决策。
当未使用类型对象(如执行纯 SQL 字符串)时,会有一个默认的 “outputtypehandler”,它通常会将指定了精度和小数位的数值作为 Python Decimal
对象返回。若出于性能考虑希望禁用这种 Decimal 强制转换,可以向 create_engine()
传入参数 coerce_to_decimal=False
:
engine = create_engine("oracle+cx_oracle://dsn", coerce_to_decimal=False)
coerce_to_decimal
标志仅影响那些未与 Numeric
SQLAlchemy 类型(或其子类)关联的纯字符串 SQL 语句的查询结果。
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).