Microsoft SQL Server¶
Support for the Microsoft SQL Server database.
The following table summarizes current support levels for database release versions.
Support type |
Versions |
---|---|
2012+ |
|
2005+ |
DBAPI Support¶
The following dialect/DBAPI options are available. Please refer to individual DBAPI sections for connect information.
外部方言¶
External Dialects
除了上述原生支持 SQLAlchemy 的 DBAPI 层之外,还有其他与 SQL Server 兼容的 DBAPI 层的第三方方言。请参阅:ref:dialect_toplevel 页面上的“外部方言”列表。
In addition to the above DBAPI layers with native SQLAlchemy support, there are third-party dialects for other DBAPI layers that are compatible with SQL Server. See the “External Dialects” list on the Dialects page.
自动增量行为 / IDENTITY 列¶
Auto Increment Behavior / IDENTITY Columns
SQL Server 使用 IDENTITY
构造提供所谓的“自增”功能,可用于表中的任意单个整数列。
SQLAlchemy 将 IDENTITY
视为默认整数主键列的 “autoincrement” 行为的一部分,详见 Column.autoincrement
。
这意味着,默认情况下,Table
中的第一个整数主键列将被视为标识列(除非它绑定了一个 Sequence
),并将生成如下 DDL:
from sqlalchemy import Table, MetaData, Column, Integer
m = MetaData()
t = Table(
"t",
m,
Column("id", Integer, primary_key=True),
Column("x", Integer),
)
m.create_all(engine)
上述示例将生成如下 DDL:
CREATE TABLE t (
id INTEGER NOT NULL IDENTITY,
x INTEGER NULL,
PRIMARY KEY (id)
)
如果不希望默认生成 IDENTITY
,可在首个整数主键列上将 Column.autoincrement
显式设置为 False
:
m = MetaData()
t = Table(
"t",
m,
Column("id", Integer, primary_key=True, autoincrement=False),
Column("x", Integer),
)
m.create_all(engine)
要将 IDENTITY
用于非主键列,可在目标 Column
上设置 autoincrement=True
,同时确保任何整数主键列的 autoincrement
设置为 False
:
m = MetaData()
t = Table(
"t",
m,
Column("id", Integer, primary_key=True, autoincrement=False),
Column("x", Integer, autoincrement=True),
)
m.create_all(engine)
自 1.4 版本弃用: 传递给 Column
的 mssql_identity_start
与 mssql_identity_increment
参数已弃用,应使用 Identity
对象替代。
若同时指定两种配置方式将导致编译错误。
此外,这两个参数也不再出现在 Inspector.get_columns()
方法返回结果中的 dialect_options
字段下,应使用 identity
字段获取相关信息。
备注
每个表只能存在一个 IDENTITY 列。当通过 autoincrement=True
启用 IDENTITY 关键字时,SQLAlchemy 不会限制多个列同时指定该选项的行为。
数据库自身将在执行 CREATE TABLE
时拒绝这种定义。
备注
若向标有 IDENTITY 的列插入值,SQL Server 将拒绝该 INSERT 语句。
若要允许插入值,必须启用会话级的 “SET IDENTITY_INSERT” 选项。
SQLAlchemy 的 SQL Server 方言在使用核心层的 Insert
构造时会自动启用该选项;
若执行时明确为 IDENTITY 列提供值,则将在语句执行期间启用 “IDENTITY_INSERT”。
不过,这种方式性能较低,不应作为常规方案使用。
若表中的整数主键列并不需要 IDENTITY 行为,应在建表时设置 autoincrement=False
来禁用该关键字。
SQL Server provides so-called “auto incrementing” behavior using the
IDENTITY
construct, which can be placed on any single integer column in a
table. SQLAlchemy considers IDENTITY
within its default “autoincrement”
behavior for an integer primary key column, described at
Column.autoincrement
. This means that by default,
the first integer primary key column in a Table
will be
considered to be the identity column - unless it is associated with a
Sequence
- and will generate DDL as such:
from sqlalchemy import Table, MetaData, Column, Integer
m = MetaData()
t = Table(
"t",
m,
Column("id", Integer, primary_key=True),
Column("x", Integer),
)
m.create_all(engine)
The above example will generate DDL as:
CREATE TABLE t (
id INTEGER NOT NULL IDENTITY,
x INTEGER NULL,
PRIMARY KEY (id)
)
For the case where this default generation of IDENTITY
is not desired,
specify False
for the Column.autoincrement
flag,
on the first integer primary key column:
m = MetaData()
t = Table(
"t",
m,
Column("id", Integer, primary_key=True, autoincrement=False),
Column("x", Integer),
)
m.create_all(engine)
To add the IDENTITY
keyword to a non-primary key column, specify
True
for the Column.autoincrement
flag on the desired
Column
object, and ensure that
Column.autoincrement
is set to False
on any integer primary key column:
m = MetaData()
t = Table(
"t",
m,
Column("id", Integer, primary_key=True, autoincrement=False),
Column("x", Integer, autoincrement=True),
)
m.create_all(engine)
在 1.4 版本发生变更: Added Identity
construct
in a Column
to specify the start and increment
parameters of an IDENTITY. These replace
the use of the Sequence
object in order to specify these values.
自 1.4 版本弃用: The mssql_identity_start
and mssql_identity_increment
parameters
to Column
are deprecated and should we replaced by
an Identity
object. Specifying both ways of configuring
an IDENTITY will result in a compile error.
These options are also no longer returned as part of the
dialect_options
key in Inspector.get_columns()
.
Use the information in the identity
key instead.
在 1.4 版本发生变更: Removed the ability to use a Sequence
object to modify IDENTITY characteristics. Sequence
objects
now only manipulate true T-SQL SEQUENCE types.
备注
There can only be one IDENTITY column on the table. When using
autoincrement=True
to enable the IDENTITY keyword, SQLAlchemy does not
guard against multiple columns specifying the option simultaneously. The
SQL Server database will instead reject the CREATE TABLE
statement.
备注
An INSERT statement which attempts to provide a value for a column that is
marked with IDENTITY will be rejected by SQL Server. In order for the
value to be accepted, a session-level option “SET IDENTITY_INSERT” must be
enabled. The SQLAlchemy SQL Server dialect will perform this operation
automatically when using a core Insert
construct; if the
execution specifies a value for the IDENTITY column, the “IDENTITY_INSERT”
option will be enabled for the span of that statement’s invocation.However,
this scenario is not high performing and should not be relied upon for
normal use. If a table doesn’t actually require IDENTITY behavior in its
integer primary key column, the keyword should be disabled when creating
the table by ensuring that autoincrement=False
is set.
控制“起始”和“增量”¶
Controlling “Start” and “Increment”
要精确控制 IDENTITY
的起始值与增量值,可将 Identity
传入 Column
,并使用其 Identity.start
和 Identity.increment
参数:
from sqlalchemy import Table, Integer, Column, Identity
test = Table(
"test",
metadata,
Column(
"id", Integer, primary_key=True, Identity(start=100, increment=10)
),
Column("name", String(20)),
)
上述 Table
对象将生成如下 CREATE TABLE 语句:
CREATE TABLE test (
id INTEGER NOT NULL IDENTITY(100,10) PRIMARY KEY,
name VARCHAR(20) NULL,
)
备注
Identity
对象除了 start
与 increment
外,还支持多个其他参数。
然而 SQL Server 并不支持这些额外参数,因此它们在生成 DDL 时将被忽略。
Specific control over the “start” and “increment” values for
the IDENTITY
generator are provided using the
Identity.start
and Identity.increment
parameters passed to the Identity
object:
from sqlalchemy import Table, Integer, Column, Identity
test = Table(
"test",
metadata,
Column(
"id", Integer, primary_key=True, Identity(start=100, increment=10)
),
Column("name", String(20)),
)
The CREATE TABLE for the above Table
object would be:
- CREATE TABLE test (
id INTEGER NOT NULL IDENTITY(100,10) PRIMARY KEY, name VARCHAR(20) NULL,
)
备注
The Identity
object supports many other parameter in
addition to start
and increment
. These are not supported by
SQL Server and will be ignored when generating the CREATE TABLE ddl.
将 IDENTITY 与非整数数值类型结合使用¶
Using IDENTITY with Non-Integer numeric types
SQL Server 还允许在 NUMERIC
列上使用 IDENTITY
。
为在 SQLAlchemy 中顺利实现此模式,建议列的主类型仍为 Integer
,但可通过 TypeEngine.with_variant()
方法将其在底层数据库中具体实现为 Numeric
:
from sqlalchemy import Column
from sqlalchemy import Integer
from sqlalchemy import Numeric
from sqlalchemy import String
from sqlalchemy.ext.declarative import declarative_base
Base = declarative_base()
class TestTable(Base):
__tablename__ = "test"
id = Column(
Integer().with_variant(Numeric(10, 0), "mssql"),
primary_key=True,
autoincrement=True,
)
name = Column(String)
在上述示例中,使用 Integer().with_variant()
明确表达了意图。
关于 autoincrement
仅适用于 Integer
类型的限制,是在元数据层面定义的,而非每个方言各自决定的。
采用上述模式时,插入行所返回的主键标识符(即赋值给 ORM 实例,如上例中的 TestTable
的 id)将是 Decimal()
实例,而不是 int
,因为 SQL Server 返回的数值类型是 Numeric
。
若希望该返回类型为浮点数,可向 Numeric.asdecimal
传入 False
。
若希望将 Numeric(10, 0)
类型的值归一化为 Python 的整数类型(在 Python 3 中也支持任意精度长整型),可使用 TypeDecorator
进行如下封装:
from sqlalchemy import TypeDecorator
class NumericAsInteger(TypeDecorator):
"将浮点返回值规范化为整数"
impl = Numeric(10, 0, asdecimal=False)
cache_ok = True
def process_result_value(self, value, dialect):
if value is not None:
value = int(value)
return value
class TestTable(Base):
__tablename__ = "test"
id = Column(
Integer().with_variant(NumericAsInteger, "mssql"),
primary_key=True,
autoincrement=True,
)
name = Column(String)
SQL Server also allows IDENTITY
to be used with NUMERIC
columns. To
implement this pattern smoothly in SQLAlchemy, the primary datatype of the
column should remain as Integer
, however the underlying implementation
type deployed to the SQL Server database can be specified as Numeric
using
TypeEngine.with_variant()
:
from sqlalchemy import Column
from sqlalchemy import Integer
from sqlalchemy import Numeric
from sqlalchemy import String
from sqlalchemy.ext.declarative import declarative_base
Base = declarative_base()
class TestTable(Base):
__tablename__ = "test"
id = Column(
Integer().with_variant(Numeric(10, 0), "mssql"),
primary_key=True,
autoincrement=True,
)
name = Column(String)
In the above example, Integer().with_variant()
provides clear usage
information that accurately describes the intent of the code. The general
restriction that autoincrement
only applies to Integer
is established
at the metadata level and not at the per-dialect level.
When using the above pattern, the primary key identifier that comes back from
the insertion of a row, which is also the value that would be assigned to an
ORM object such as TestTable
above, will be an instance of Decimal()
and not int
when using SQL Server. The numeric return type of the
Numeric
type can be changed to return floats by passing False
to Numeric.asdecimal
. To normalize the return type of the
above Numeric(10, 0)
to return Python ints (which also support “long”
integer values in Python 3), use TypeDecorator
as follows:
from sqlalchemy import TypeDecorator
class NumericAsInteger(TypeDecorator):
"normalize floating point return values into ints"
impl = Numeric(10, 0, asdecimal=False)
cache_ok = True
def process_result_value(self, value, dialect):
if value is not None:
value = int(value)
return value
class TestTable(Base):
__tablename__ = "test"
id = Column(
Integer().with_variant(NumericAsInteger, "mssql"),
primary_key=True,
autoincrement=True,
)
name = Column(String)
INSERT 行为¶
INSERT behavior
处理 IDENTITY
列的插入时间涉及两种关键技术。最常见的做法是能够获取给定 IDENTITY
列的“最后插入值”,这个过程在许多情况下由 SQLAlchemy 隐式执行,最重要的是在 ORM 中。
获取此值的过程有几种变体:
在绝大多数情况下,SQL Server 中的 INSERT 语句会与 RETURNING 一起使用,以获取新生成的主键值:
INSERT INTO t (x) OUTPUT inserted.id VALUES (?)
从 SQLAlchemy 2.0 开始,默认情况下也会使用 INSERT 语句的“插入多个值”行为 特性来优化多行 INSERT 语句;对于 SQL Server,这个特性会作用于带有 RETURNING 和不带 RETURNING 的 INSERT 语句。
在 2.0.10 版本发生变更: 由于行排序问题,SQLAlchemy 2.0.9 暂时禁用了 SQL Server 的 INSERT 语句的“插入多个值”行为 特性。 从 2.0.10 开始,该特性已重新启用,并针对事务单元要求的 RETURNING 排序进行了特殊处理。
当 RETURNING 不可用或通过
implicit_returning=False
被禁用时,将使用scope_identity()
函数或@@identity
变量;行为依据后端不同而有所不同:在使用 PyODBC 时,会在 INSERT 语句的末尾附加
; select scope_identity()
;会获取第二个结果集以接收值。给定如下表:- t = Table(
“t”, metadata, Column(“id”, Integer, primary_key=True), Column(“x”, Integer), implicit_returning=False,
)
一个 INSERT 语句将如下所示:
INSERT INTO t (x) VALUES (?); select scope_identity()
其他方言如 pymssql 会在 INSERT 语句之后调用
SELECT scope_identity() AS lastrowid
。如果将use_scope_identity=False
传递给create_engine()
,则会使用SELECT @@identity AS lastrowid
代替。
包含 IDENTITY
列的表将禁止显式引用身份列的 INSERT 语句。SQLAlchemy 方言会检测到当通过核心 insert()
构造(而非普通字符串 SQL)创建的 INSERT 构造中引用了身份列,并在这种情况下会在执行插入语句前发出 SET IDENTITY_INSERT ON
,执行后发出 SET IDENTITY_INSERT OFF
。给定如下示例:
m = MetaData() t = Table(
“t”, m, Column(“id”, Integer, primary_key=True), Column(“x”, Integer)
) m.create_all(engine)
- with engine.begin() as conn:
conn.execute(t.insert(), {“id”: 1, “x”: 1}, {“id”: 2, “x”: 2})
上述列将以 IDENTITY 创建,但我们发出的 INSERT 语句指定了显式值。在回显输出中我们可以看到 SQLAlchemy 如何处理:
CREATE TABLE t (
id INTEGER NOT NULL IDENTITY(1,1),
x INTEGER NULL,
PRIMARY KEY (id)
)
COMMIT
SET IDENTITY_INSERT t ON
INSERT INTO t (id, x) VALUES (?, ?)
((1, 1), (2, 2))
SET IDENTITY_INSERT t OFF
COMMIT
这是一个适用于测试和批量插入场景的辅助用例。
Handling of the IDENTITY
column at INSERT time involves two key
techniques. The most common is being able to fetch the “last inserted value”
for a given IDENTITY
column, a process which SQLAlchemy performs
implicitly in many cases, most importantly within the ORM.
The process for fetching this value has several variants:
In the vast majority of cases, RETURNING is used in conjunction with INSERT statements on SQL Server in order to get newly generated primary key values:
INSERT INTO t (x) OUTPUT inserted.id VALUES (?)
As of SQLAlchemy 2.0, the INSERT 语句的“插入多个值”行为 feature is also used by default to optimize many-row INSERT statements; for SQL Server the feature takes place for both RETURNING and-non RETURNING INSERT statements.
在 2.0.10 版本发生变更: The INSERT 语句的“插入多个值”行为 feature for SQL Server was temporarily disabled for SQLAlchemy version 2.0.9 due to issues with row ordering. As of 2.0.10 the feature is re-enabled, with special case handling for the unit of work’s requirement for RETURNING to be ordered.
When RETURNING is not available or has been disabled via
implicit_returning=False
, either thescope_identity()
function or the@@identity
variable is used; behavior varies by backend:when using PyODBC, the phrase
; select scope_identity()
will be appended to the end of the INSERT statement; a second result set will be fetched in order to receive the value. Given a table as:t = Table( "t", metadata, Column("id", Integer, primary_key=True), Column("x", Integer), implicit_returning=False, )
an INSERT will look like:
INSERT INTO t (x) VALUES (?); select scope_identity()
Other dialects such as pymssql will call upon
SELECT scope_identity() AS lastrowid
subsequent to an INSERT statement. If the flaguse_scope_identity=False
is passed tocreate_engine()
, the statementSELECT @@identity AS lastrowid
is used instead.
A table that contains an IDENTITY
column will prohibit an INSERT statement
that refers to the identity column explicitly. The SQLAlchemy dialect will
detect when an INSERT construct, created using a core
insert()
construct (not a plain string SQL), refers to the identity column, and
in this case will emit SET IDENTITY_INSERT ON
prior to the insert
statement proceeding, and SET IDENTITY_INSERT OFF
subsequent to the
execution. Given this example:
m = MetaData()
t = Table(
"t", m, Column("id", Integer, primary_key=True), Column("x", Integer)
)
m.create_all(engine)
with engine.begin() as conn:
conn.execute(t.insert(), {"id": 1, "x": 1}, {"id": 2, "x": 2})
The above column will be created with IDENTITY, however the INSERT statement we emit is specifying explicit values. In the echo output we can see how SQLAlchemy handles this:
CREATE TABLE t (
id INTEGER NOT NULL IDENTITY(1,1),
x INTEGER NULL,
PRIMARY KEY (id)
)
COMMIT
SET IDENTITY_INSERT t ON
INSERT INTO t (id, x) VALUES (?, ?)
((1, 1), (2, 2))
SET IDENTITY_INSERT t OFF
COMMIT
This is an auxiliary use case suitable for testing and bulk insert scenarios.
SEQUENCE 支持¶
SEQUENCE support
Sequence
对象创建“真实”序列,即 CREATE SEQUENCE
:
>>> from sqlalchemy import Sequence
>>> from sqlalchemy.schema import CreateSequence
>>> from sqlalchemy.dialects import mssql
>>> print(
... CreateSequence(Sequence("my_seq", start=1)).compile(
... dialect=mssql.dialect()
... )
... )
CREATE SEQUENCE my_seq START WITH 1
对于整数主键生成,SQL Server 的 IDENTITY
构造通常应优先于序列。
小技巧
T-SQL 的默认起始值是 -2**63
,而不是大多数其他 SQL 数据库中的 1。用户应显式将 Sequence.start
设置为 1(如果这是期望的默认值):
seq = Sequence(“my_sequence”, start=1)
在 1.4 版本加入: 添加了 SQL Server 对 Sequence
的支持
在 2.0 版本发生变更: SQL Server 方言将不再隐式渲染 CREATE SEQUENCE
中的 “START WITH 1”,这在 1.4 版本中首次实现。
The Sequence
object creates “real” sequences, i.e.,
CREATE SEQUENCE
:
>>> from sqlalchemy import Sequence
>>> from sqlalchemy.schema import CreateSequence
>>> from sqlalchemy.dialects import mssql
>>> print(
... CreateSequence(Sequence("my_seq", start=1)).compile(
... dialect=mssql.dialect()
... )
... )
CREATE SEQUENCE my_seq START WITH 1
For integer primary key generation, SQL Server’s IDENTITY
construct should
generally be preferred vs. sequence.
小技巧
The default start value for T-SQL is -2**63
instead of 1 as
in most other SQL databases. Users should explicitly set the
Sequence.start
to 1 if that’s the expected default:
seq = Sequence("my_sequence", start=1)
在 1.4 版本加入: added SQL Server support for Sequence
在 2.0 版本发生变更: The SQL Server dialect will no longer implicitly
render “START WITH 1” for CREATE SEQUENCE
, which was the behavior
first implemented in version 1.4.
VARCHAR / NVARCHAR 上的 MAX¶
MAX on VARCHAR / NVARCHAR
SQL Server 支持在 VARCHAR
和 NVARCHAR
数据类型中使用特殊字符串 “MAX” 来表示“最大长度”。该方言目前将其作为基本类型中的 “None” 长度处理,而不是提供这些类型的方言特定版本,这样指定如 VARCHAR(None)
的基本类型可以在多个后端上假设为“无长度”行为,而不使用特定方言的类型。
要构建一个 SQL Server VARCHAR 或 NVARCHAR 最大长度的列,可以使用 None:
- my_table = Table(
“my_table”, metadata, Column(“my_data”, VARCHAR(None)), Column(“my_n_data”, NVARCHAR(None)),
)
SQL Server supports the special string “MAX” within the
VARCHAR
and NVARCHAR
datatypes,
to indicate “maximum length possible”. The dialect currently handles this as
a length of “None” in the base type, rather than supplying a
dialect-specific version of these types, so that a base type
specified such as VARCHAR(None)
can assume “unlengthed” behavior on
more than one backend without using dialect-specific types.
To build a SQL Server VARCHAR or NVARCHAR with MAX length, use None:
my_table = Table(
"my_table",
metadata,
Column("my_data", VARCHAR(None)),
Column("my_n_data", NVARCHAR(None)),
)
排序规则支持¶
Collation Support
字符排序规则由基本字符串类型支持,通过字符串参数 “collation” 指定:
from sqlalchemy import VARCHAR
Column(“login”, VARCHAR(32, collation=”Latin1_General_CI_AS”))
当这样的列与 Table
关联时,生成的 CREATE TABLE 语句将如下所示:
login VARCHAR(32) COLLATE Latin1_General_CI_AS NULL
Character collations are supported by the base string types, specified by the string argument “collation”:
from sqlalchemy import VARCHAR
Column("login", VARCHAR(32, collation="Latin1_General_CI_AS"))
When such a column is associated with a Table
, the
CREATE TABLE statement for this column will yield:
login VARCHAR(32) COLLATE Latin1_General_CI_AS NULL
LIMIT/OFFSET 支持¶
LIMIT/OFFSET Support
自 SQL Server 2012 起,MSSQL 支持通过 “OFFSET n ROWS” 和 “FETCH NEXT n ROWS” 子句添加了对 LIMIT / OFFSET 的支持。如果检测到 SQL Server 2012 或更高版本,SQLAlchemy 会自动支持这些语法。
在 1.4 版本发生变更: 添加了对 SQL Server “OFFSET n ROWS” 和 “FETCH NEXT n ROWS” 语法的支持。
对于只指定 LIMIT 而没有 OFFSET 的语句,所有版本的 SQL Server 都支持 TOP 关键字。此语法在没有 OFFSET 子句的情况下用于所有 SQL Server 版本。像如下的语句:
select(some_table).limit(5)
将会转换为类似以下的 SQL:
SELECT TOP 5 col1, col2.. FROM table
对于 SQL Server 2012 之前的版本,使用 LIMIT 和 OFFSET,或者仅使用 OFFSET 的语句将会通过 ROW_NUMBER()
窗口函数进行转换。像如下的语句:
select(some_table).order_by(some_table.c.col3).limit(5).offset(10)
将会转换为类似以下的 SQL:
SELECT anon_1.col1, anon_1.col2 FROM (SELECT col1, col2,
ROW_NUMBER() OVER (ORDER BY col3) AS
mssql_rn FROM table WHERE t.x = :x_1) AS
anon_1 WHERE mssql_rn > :param_1 AND mssql_rn <= :param_2 + :param_1
请注意,在使用 LIMIT 和/或 OFFSET 时,无论使用旧的还是新的 SQL Server 语法,语句都必须包含 ORDER BY,否则将抛出 CompileError
。
MSSQL has added support for LIMIT / OFFSET as of SQL Server 2012, via the “OFFSET n ROWS” and “FETCH NEXT n ROWS” clauses. SQLAlchemy supports these syntaxes automatically if SQL Server 2012 or greater is detected.
在 1.4 版本发生变更: support added for SQL Server “OFFSET n ROWS” and “FETCH NEXT n ROWS” syntax.
For statements that specify only LIMIT and no OFFSET, all versions of SQL Server support the TOP keyword. This syntax is used for all SQL Server versions when no OFFSET clause is present. A statement such as:
select(some_table).limit(5)
will render similarly to:
SELECT TOP 5 col1, col2.. FROM table
For versions of SQL Server prior to SQL Server 2012, a statement that uses
LIMIT and OFFSET, or just OFFSET alone, will be rendered using the
ROW_NUMBER()
window function. A statement such as:
select(some_table).order_by(some_table.c.col3).limit(5).offset(10)
will render similarly to:
SELECT anon_1.col1, anon_1.col2 FROM (SELECT col1, col2,
ROW_NUMBER() OVER (ORDER BY col3) AS
mssql_rn FROM table WHERE t.x = :x_1) AS
anon_1 WHERE mssql_rn > :param_1 AND mssql_rn <= :param_2 + :param_1
Note that when using LIMIT and/or OFFSET, whether using the older
or newer SQL Server syntaxes, the statement must have an ORDER BY as well,
else a CompileError
is raised.
DDL 注释支持¶
DDL Comment Support
评论支持,包括对 Table.comment
和 Column.comment
等属性的 DDL 渲染,以及反射这些注释的功能,在使用支持的 SQL Server 版本时得到支持。如果首次连接时检测到不支持的版本(如 Azure Synapse),通过检查 fn_listextendedproperty
SQL 函数的存在,则会禁用评论支持,包括渲染和表注释反射,因为这两个功能依赖于 SQL Server 存储过程和函数,而这些在并非所有后端类型中可用。
要强制开启或关闭评论支持,可以绕过自动检测,在 create_engine()
中设置 supports_comments
参数:
e = create_engine(“mssql+pyodbc://u:p@dsn”, supports_comments=False)
在 2.0 版本加入: 为 SQL Server 方言添加了对表和列注释的支持,包括 DDL 生成和反射。
Comment support, which includes DDL rendering for attributes such as
Table.comment
and Column.comment
, as
well as the ability to reflect these comments, is supported assuming a
supported version of SQL Server is in use. If a non-supported version such as
Azure Synapse is detected at first-connect time (based on the presence
of the fn_listextendedproperty
SQL function), comment support including
rendering and table-comment reflection is disabled, as both features rely upon
SQL Server stored procedures and functions that are not available on all
backend types.
To force comment support to be on or off, bypassing autodetection, set the
parameter supports_comments
within create_engine()
:
e = create_engine("mssql+pyodbc://u:p@dsn", supports_comments=False)
在 2.0 版本加入: Added support for table and column comments for the SQL Server dialect, including DDL generation and reflection.
事务隔离级别¶
Transaction Isolation Level
所有 SQL Server 方言都支持通过方言特定的参数 create_engine.isolation_level
来设置事务隔离级别,该参数由 create_engine()
接受,以及传递给 Connection.execution_options()
的 Connection.execution_options.isolation_level
参数。此功能通过为每个新连接发出 SET TRANSACTION ISOLATION LEVEL <level>
命令来工作。
使用 create_engine()
设置隔离级别:
- engine = create_engine(
“mssql+pyodbc://scott:tiger@ms_2008”, isolation_level=”REPEATABLE READ”
)
使用每连接执行选项设置:
connection = engine.connect() connection = connection.execution_options(isolation_level=”READ COMMITTED”)
isolation_level
的有效值包括:
AUTOCOMMIT
- pyodbc / pymssql 特有READ COMMITTED
READ UNCOMMITTED
REPEATABLE READ
SERIALIZABLE
SNAPSHOT
- SQL Server 特有
隔离级别配置还有更多选项,例如链接到主 Engine
的“子引擎”对象,每个对象应用不同的隔离级别设置。有关背景信息,请参见 设置事务隔离级别(包括 DBAPI 自动提交)。
All SQL Server dialects support setting of transaction isolation level
both via a dialect-specific parameter
create_engine.isolation_level
accepted by create_engine()
,
as well as the Connection.execution_options.isolation_level
argument as passed to
Connection.execution_options()
.
This feature works by issuing the
command SET TRANSACTION ISOLATION LEVEL <level>
for
each new connection.
To set isolation level using create_engine()
:
engine = create_engine(
"mssql+pyodbc://scott:tiger@ms_2008", isolation_level="REPEATABLE READ"
)
To set using per-connection execution options:
connection = engine.connect()
connection = connection.execution_options(isolation_level="READ COMMITTED")
Valid values for isolation_level
include:
AUTOCOMMIT
- pyodbc / pymssql-specificREAD COMMITTED
READ UNCOMMITTED
REPEATABLE READ
SERIALIZABLE
SNAPSHOT
- specific to SQL Server
There are also more options for isolation level configurations, such as
“sub-engine” objects linked to a main Engine
which each apply
different isolation level settings. See the discussion at
设置事务隔离级别(包括 DBAPI 自动提交) for background.
连接池的临时表/资源重置¶
Temporary Table / Resource Reset for Connection Pooling
SQLAlchemy Engine
对象使用的 QueuePool
连接池实现包括 reset on return 行为,当连接返回到连接池时,会调用 DBAPI 的 .rollback()
方法。虽然此回滚将清除上一个事务使用的即时状态,但它并不涵盖会话级别的更广泛状态,包括临时表以及其他服务器状态,如预处理语句句柄和语句缓存。已知 SQL Server 有一个未记录的存储过程 sp_reset_connection
,它是解决此问题的一个变通方法,可以重置连接上的大部分会话状态,包括临时表。
要将 sp_reset_connection
安装为执行 reset-on-return 的方法,可以使用 PoolEvents.reset()
事件钩子,如下例所示。通过将 create_engine.pool_reset_on_return
参数设置为 None
,以便自定义方案可以完全替代默认行为。自定义钩子实现会在任何情况下调用 .rollback()
,因为通常需要确保 DBAPI 自身的提交/回滚跟踪与事务的状态保持一致:
from sqlalchemy import create_engine from sqlalchemy import event
- mssql_engine = create_engine(
“mssql+pyodbc://scott:tiger^5HHH@mssql2017:1433/test?driver=ODBC+Driver+17+for+SQL+Server”, # 禁用默认的 reset-on-return 方案 pool_reset_on_return=None,
)
@event.listens_for(mssql_engine, “reset”) def _reset_mssql(dbapi_connection, connection_record, reset_state):
- if not reset_state.terminate_only:
dbapi_connection.execute(“{call sys.sp_reset_connection}”)
# 以便 DBAPI 本身知道连接已被重置 dbapi_connection.rollback()
在 2.0.0b3 版本发生变更: 为 PoolEvents.reset()
事件添加了额外的状态参数,并确保在所有“重置”发生时调用该事件,以便它适合作为自定义“重置”处理程序的地方。以前使用 PoolEvents.checkin()
处理程序的方案仍然可用。
The QueuePool
connection pool implementation used
by the SQLAlchemy Engine
object includes
reset on return behavior that will invoke
the DBAPI .rollback()
method when connections are returned to the pool.
While this rollback will clear out the immediate state used by the previous
transaction, it does not cover a wider range of session-level state, including
temporary tables as well as other server state such as prepared statement
handles and statement caches. An undocumented SQL Server procedure known
as sp_reset_connection
is known to be a workaround for this issue which
will reset most of the session state that builds up on a connection, including
temporary tables.
To install sp_reset_connection
as the means of performing reset-on-return,
the PoolEvents.reset()
event hook may be used, as demonstrated in the
example below. The create_engine.pool_reset_on_return
parameter
is set to None
so that the custom scheme can replace the default behavior
completely. The custom hook implementation calls .rollback()
in any case,
as it’s usually important that the DBAPI’s own tracking of commit/rollback
will remain consistent with the state of the transaction:
from sqlalchemy import create_engine
from sqlalchemy import event
mssql_engine = create_engine(
"mssql+pyodbc://scott:tiger^5HHH@mssql2017:1433/test?driver=ODBC+Driver+17+for+SQL+Server",
# disable default reset-on-return scheme
pool_reset_on_return=None,
)
@event.listens_for(mssql_engine, "reset")
def _reset_mssql(dbapi_connection, connection_record, reset_state):
if not reset_state.terminate_only:
dbapi_connection.execute("{call sys.sp_reset_connection}")
# so that the DBAPI itself knows that the connection has been
# reset
dbapi_connection.rollback()
在 2.0.0b3 版本发生变更: Added additional state arguments to
the PoolEvents.reset()
event and additionally ensured the event
is invoked for all “reset” occurrences, so that it’s appropriate
as a place for custom “reset” handlers. Previous schemes which
use the PoolEvents.checkin()
handler remain usable as well.
可空性¶
Nullability
MSSQL 支持三种列的空值可用性级别。默认的空值可用性允许空值,并在 CREATE TABLE 语句中明确指定:
name VARCHAR(20) NULL
如果指定 nullable=None
,则不做任何指定。换句话说,使用数据库配置的默认值。这将会渲染为:
name VARCHAR(20)
如果 nullable
为 True
或 False
,则列将分别为 NULL
或 NOT NULL
。
MSSQL has support for three levels of column nullability. The default nullability allows nulls and is explicit in the CREATE TABLE construct:
name VARCHAR(20) NULL
If nullable=None
is specified then no specification is made. In
other words the database’s configured default is used. This will
render:
name VARCHAR(20)
If nullable
is True
or False
then the column will be
NULL
or NOT NULL
respectively.
日期/时间处理¶
Date / Time Handling
DATE 和 TIME 类型是支持的。绑定参数将根据大多数 MSSQL 驱动程序的要求转换为 datetime.datetime() 对象,并且如果需要,结果将从字符串中进行处理。对于 SQL Server 2005 及之前的版本,DATE 和 TIME 类型不可用。如果检测到 2008 以下的服务器版本,这些类型的 DDL 将会作为 DATETIME 类型发出。
DATE and TIME are supported. Bind parameters are converted to datetime.datetime() objects as required by most MSSQL drivers, and results are processed from strings if needed. The DATE and TIME types are not available for MSSQL 2005 and previous - if a server version below 2008 is detected, DDL for these types will be issued as DATETIME.
大型文本/二进制类型弃用¶
Large Text/Binary Type Deprecation
根据 SQL Server 2012/2014 文档,NTEXT
、TEXT
和 IMAGE
数据类型将在未来的 SQL Server 版本中被移除。SQLAlchemy 通常将这些类型与 UnicodeText
、TextClause
和 LargeBinary
数据类型相关联。
为了适应这一变化,方言中新增了一个标志 deprecate_large_types
,该标志将在首次连接时自动根据使用的服务器版本进行设置,除非用户另行设置。该标志的行为如下:
当该标志为
True
时,使用UnicodeText
、TextClause
和LargeBinary
数据类型进行 DDL 渲染时,将分别渲染为NVARCHAR(max)
、VARCHAR(max)
和VARBINARY(max)
类型。这是添加该标志后的新行为。当该标志为
False
时,使用UnicodeText
、TextClause
和LargeBinary
数据类型进行 DDL 渲染时,将分别渲染为NTEXT
、TEXT
和IMAGE
类型。这是这些类型的长期行为。在数据库连接建立之前,标志的初始值为
None
。如果使用方言渲染 DDL 而未设置该标志,它将被解释为False
。在首次连接时,方言会检测是否使用了 SQL Server 2012 或更高版本;如果标志仍为
None
,则会根据是否检测到 2012 或更高版本,将其设置为True
或False
。在创建方言时,可以将标志设置为
True
或False
,通常通过create_engine()
完成:eng = create_engine( "mssql+pymssql://user:pass@host/db", deprecate_large_types=True )
通过使用大写类型对象,可以完全控制是否渲染“旧”或“新”类型:
NVARCHAR
、VARCHAR
、VARBINARY
、TEXT
、NTEXT
、IMAGE
,这些类型将始终固定并始终输出精确的类型。
Per
SQL Server 2012/2014 Documentation,
the NTEXT
, TEXT
and IMAGE
datatypes are to be removed from SQL
Server in a future release. SQLAlchemy normally relates these types to the
UnicodeText
, TextClause
and
LargeBinary
datatypes.
In order to accommodate this change, a new flag deprecate_large_types
is added to the dialect, which will be automatically set based on detection
of the server version in use, if not otherwise set by the user. The
behavior of this flag is as follows:
When this flag is
True
, theUnicodeText
,TextClause
andLargeBinary
datatypes, when used to render DDL, will render the typesNVARCHAR(max)
,VARCHAR(max)
, andVARBINARY(max)
, respectively. This is a new behavior as of the addition of this flag.When this flag is
False
, theUnicodeText
,TextClause
andLargeBinary
datatypes, when used to render DDL, will render the typesNTEXT
,TEXT
, andIMAGE
, respectively. This is the long-standing behavior of these types.The flag begins with the value
None
, before a database connection is established. If the dialect is used to render DDL without the flag being set, it is interpreted the same asFalse
.On first connection, the dialect detects if SQL Server version 2012 or greater is in use; if the flag is still at
None
, it sets it toTrue
orFalse
based on whether 2012 or greater is detected.The flag can be set to either
True
orFalse
when the dialect is created, typically viacreate_engine()
:eng = create_engine( "mssql+pymssql://user:pass@host/db", deprecate_large_types=True )
Complete control over whether the “old” or “new” types are rendered is available in all SQLAlchemy versions by using the UPPERCASE type objects instead:
NVARCHAR
,VARCHAR
,VARBINARY
,TEXT
,NTEXT
,IMAGE
will always remain fixed and always output exactly that type.
多部分架构名称¶
Multipart Schema Names
SQL Server 架构有时需要多个部分来组成它们的“架构”限定符,即将数据库名称和所有者名称作为独立的令牌来表示,例如 mydatabase.dbo.some_table
。可以使用 Table.schema
参数一次性设置这些多部分名称,方法如下:
Table(
"some_table",
metadata,
Column("q", String(50)),
schema="mydatabase.dbo",
)
在执行如表或组件反射等操作时,包含点的架构参数将被拆分为独立的“数据库”和“所有者”部分,以便正确查询 SQL Server 信息架构表,因为这两个值是分开存储的。此外,在为 DDL 或 SQL 渲染架构名称时,如果名称包含大小写敏感的名称或其他特殊字符,这两个组件将被分别引用。给定如下参数:
Table(
"some_table",
metadata,
Column("q", String(50)),
schema="MyDataBase.dbo",
)
上述架构将被渲染为 [MyDataBase].dbo
,并且在反射时,将使用 “dbo” 作为所有者,”MyDataBase” 作为数据库名称。
要控制架构名称如何拆分为数据库/所有者,需在名称中指定括号(在 SQL Server 中为引用字符)。如下所示,”所有者” 将被视为 MyDataBase.dbo
,而 “数据库” 将为 None:
Table(
"some_table",
metadata,
Column("q", String(50)),
schema="[MyDataBase.dbo]",
)
要单独指定包含特殊字符或嵌入点的数据库和所有者名称,可以使用两组括号:
Table(
"some_table",
metadata,
Column("q", String(50)),
schema="[MyDataBase.Period].[MyOwner.Dot]",
)
SQL Server schemas sometimes require multiple parts to their “schema”
qualifier, that is, including the database name and owner name as separate
tokens, such as mydatabase.dbo.some_table
. These multipart names can be set
at once using the Table.schema
argument of
Table
:
Table(
"some_table",
metadata,
Column("q", String(50)),
schema="mydatabase.dbo",
)
When performing operations such as table or component reflection, a schema argument that contains a dot will be split into separate “database” and “owner” components in order to correctly query the SQL Server information schema tables, as these two values are stored separately. Additionally, when rendering the schema name for DDL or SQL, the two components will be quoted separately for case sensitive names and other special characters. Given an argument as below:
Table(
"some_table",
metadata,
Column("q", String(50)),
schema="MyDataBase.dbo",
)
The above schema would be rendered as [MyDataBase].dbo
, and also in
reflection, would be reflected using “dbo” as the owner and “MyDataBase”
as the database name.
To control how the schema name is broken into database / owner,
specify brackets (which in SQL Server are quoting characters) in the name.
Below, the “owner” will be considered as MyDataBase.dbo
and the
“database” will be None:
Table(
"some_table",
metadata,
Column("q", String(50)),
schema="[MyDataBase.dbo]",
)
To individually specify both database and owner name with special characters or embedded dots, use two sets of brackets:
Table(
"some_table",
metadata,
Column("q", String(50)),
schema="[MyDataBase.Period].[MyOwner.Dot]",
)
传统架构模式¶
Legacy Schema Mode
MSSQL 方言的早期版本引入了一种行为,使得在 SELECT 语句中使用带有架构限定符的表时,该表会自动被别名;给定一个表如下:
account_table = Table(
"account",
metadata,
Column("id", Integer, primary_key=True),
Column("info", String(100)),
schema="customer_schema",
)
这种遗留模式的渲染假设 “customer_schema.account” 并不被 SQL 语句的所有部分接受,如下所示:
>>> eng = create_engine("mssql+pymssql://mydsn", legacy_schema_aliasing=True)
>>> print(account_table.select().compile(eng))
SELECT account_1.id, account_1.info
FROM customer_schema.account AS account_1
目前此行为默认已关闭,因为它似乎没有实际用途;然而,在遗留应用依赖此行为的情况下,仍可通过 legacy_schema_aliasing 参数来启用,如上所示。
自 1.4 版本弃用: legacy_schema_aliasing
标志现在已被弃用,并将在未来的版本中移除。
Very old versions of the MSSQL dialect introduced the behavior such that a schema-qualified table would be auto-aliased when used in a SELECT statement; given a table:
account_table = Table(
"account",
metadata,
Column("id", Integer, primary_key=True),
Column("info", String(100)),
schema="customer_schema",
)
this legacy mode of rendering would assume that “customer_schema.account” would not be accepted by all parts of the SQL statement, as illustrated below:
>>> eng = create_engine("mssql+pymssql://mydsn", legacy_schema_aliasing=True)
>>> print(account_table.select().compile(eng))
SELECT account_1.id, account_1.info
FROM customer_schema.account AS account_1
This mode of behavior is now off by default, as it appears to have served
no purpose; however in the case that legacy applications rely upon it,
it is available using the legacy_schema_aliasing
argument to
create_engine()
as illustrated above.
自 1.4 版本弃用: The legacy_schema_aliasing
flag is now
deprecated and will be removed in a future release.
聚集索引支持¶
Clustered Index Support
MSSQL 方言通过 mssql_clustered
选项支持聚集索引(以及主键)。该选项可用于 Index
、UniqueConstraint
和 PrimaryKeyConstraint
。对于索引,该选项可与 mssql_columnstore
选项结合使用,以创建聚集列存储索引。
要生成聚集索引,使用如下代码:
Index("my_index", table.c.x, mssql_clustered=True)
该索引会被渲染为 CREATE CLUSTERED INDEX my_index ON table (x)
。
要生成聚集主键,使用如下代码:
- Table(
“my_table”, metadata, Column(“x”, …), Column(“y”, …), PrimaryKeyConstraint(“x”, “y”, mssql_clustered=True),
)
该表将被渲染为如下 SQL 语句:
CREATE TABLE my_table (
x INTEGER NOT NULL,
y INTEGER NOT NULL,
PRIMARY KEY CLUSTERED (x, y)
)
同样,我们可以使用以下代码生成聚集唯一约束:
- Table(
“my_table”, metadata, Column(“x”, …), Column(“y”, …), PrimaryKeyConstraint(“x”), UniqueConstraint(“y”, mssql_clustered=True),
)
要显式请求非聚集主键(例如,当需要单独的聚集索引时),使用如下代码:
- Table(
“my_table”, metadata, Column(“x”, …), Column(“y”, …), PrimaryKeyConstraint(“x”, “y”, mssql_clustered=False),
)
该表将被渲染为如下 SQL 语句:
CREATE TABLE my_table (
x INTEGER NOT NULL,
y INTEGER NOT NULL,
PRIMARY KEY NONCLUSTERED (x, y)
)
The MSSQL dialect supports clustered indexes (and primary keys) via the
mssql_clustered
option. This option is available to Index
,
UniqueConstraint
. and PrimaryKeyConstraint
.
For indexes this option can be combined with the mssql_columnstore
one
to create a clustered columnstore index.
To generate a clustered index:
Index("my_index", table.c.x, mssql_clustered=True)
which renders the index as CREATE CLUSTERED INDEX my_index ON table (x)
.
To generate a clustered primary key use:
Table(
"my_table",
metadata,
Column("x", ...),
Column("y", ...),
PrimaryKeyConstraint("x", "y", mssql_clustered=True),
)
which will render the table, for example, as:
CREATE TABLE my_table (
x INTEGER NOT NULL,
y INTEGER NOT NULL,
PRIMARY KEY CLUSTERED (x, y)
)
Similarly, we can generate a clustered unique constraint using:
Table(
"my_table",
metadata,
Column("x", ...),
Column("y", ...),
PrimaryKeyConstraint("x"),
UniqueConstraint("y", mssql_clustered=True),
)
To explicitly request a non-clustered primary key (for example, when a separate clustered index is desired), use:
Table(
"my_table",
metadata,
Column("x", ...),
Column("y", ...),
PrimaryKeyConstraint("x", "y", mssql_clustered=False),
)
which will render the table, for example, as:
CREATE TABLE my_table (
x INTEGER NOT NULL,
y INTEGER NOT NULL,
PRIMARY KEY NONCLUSTERED (x, y)
)
列存储索引支持¶
Columnstore Index Support
MSSQL 方言通过 mssql_columnstore
选项支持列存储索引。该选项可用于 Index
。它可以与 mssql_clustered
选项结合使用,以创建聚集列存储索引。
要生成列存储索引,使用如下代码:
Index("my_index", table.c.x, mssql_columnstore=True)
该索引将被渲染为 CREATE COLUMNSTORE INDEX my_index ON table (x)
。
要生成聚集列存储索引,提供空的列定义:
idx = Index("my_index", mssql_clustered=True, mssql_columnstore=True)
# 需要将索引与表关联
table.append_constraint(idx)
上述代码将会渲染为 CREATE CLUSTERED COLUMNSTORE INDEX my_index ON table
。
The MSSQL dialect supports columnstore indexes via the mssql_columnstore
option. This option is available to Index
. It be combined with
the mssql_clustered
option to create a clustered columnstore index.
To generate a columnstore index:
Index("my_index", table.c.x, mssql_columnstore=True)
which renders the index as CREATE COLUMNSTORE INDEX my_index ON table (x)
.
To generate a clustered columnstore index provide no columns:
idx = Index("my_index", mssql_clustered=True, mssql_columnstore=True)
# required to associate the index with the table
table.append_constraint(idx)
the above renders the index as
CREATE CLUSTERED COLUMNSTORE INDEX my_index ON table
.
在 2.0.18 版本加入.
MSSQL 特定索引选项¶
MSSQL-Specific Index Options
除了集群之外,MSSQL 方言还支持 Index
的其他特殊选项。
In addition to clustering, the MSSQL dialect supports other special options for Index
.
INCLUDE¶
INCLUDE
mssql_include
选项会将给定字符串名称渲染为 INCLUDE(colname):
Index("my_index", table.c.x, mssql_include=["y"])
会将索引渲染为 CREATE INDEX my_index ON table (x) INCLUDE (y)
The mssql_include
option renders INCLUDE(colname) for the given string names:
Index("my_index", table.c.x, mssql_include=["y"])
would render the index as CREATE INDEX my_index ON table (x) INCLUDE (y)
筛选索引¶
Filtered Indexes
mssql_where
选项会针对给定的字符串名称渲染 WHERE(condition) 语句:
Index("my_index", table.c.x, mssql_where=table.c.x > 10)
会将索引渲染为 CREATE INDEX my_index ON table (x) WHERE x > 10
。
The mssql_where
option renders WHERE(condition) for the given string names:
Index("my_index", table.c.x, mssql_where=table.c.x > 10)
would render the index as CREATE INDEX my_index ON table (x) WHERE x > 10
.
索引排序¶
Index ordering
兼容级别¶
Compatibility Levels
MSSQL 支持在数据库级别设置兼容性级别。这允许,例如,在 SQL2005 数据库服务器上运行与 SQL2000 兼容的数据库。server_version_info
始终返回数据库服务器版本信息(在这种情况下为 SQL2005),而不是兼容性级别信息。因此,如果在向后兼容模式下运行,SQLAlchemy 可能会尝试使用数据库服务器无法解析的 T-SQL 语句。
MSSQL supports the notion of setting compatibility levels at the
database level. This allows, for instance, to run a database that
is compatible with SQL2000 while running on a SQL2005 database
server. server_version_info
will always return the database
server version information (in this case SQL2005) and not the
compatibility level information. Because of this, if running under
a backwards compatibility mode SQLAlchemy may attempt to use T-SQL
statements that are unable to be parsed by the database server.
触发器¶
Triggers
默认情况下,SQLAlchemy 使用 OUTPUT INSERTED 来获取通过 IDENTITY 列或其他服务器端默认值生成的新主键值。MS-SQL 不允许在具有触发器的表上使用 OUTPUT INSERTED。要禁用在每个表级别上使用 OUTPUT INSERTED,可以为每个具有触发器的 Table
指定 implicit_returning=False
:
Table(
"mytable",
metadata,
Column("id", Integer, primary_key=True),
# ...,
implicit_returning=False,
)
声明式形式:
class MyClass(Base):
# ...
__table_args__ = {"implicit_returning": False}
SQLAlchemy by default uses OUTPUT INSERTED to get at newly
generated primary key values via IDENTITY columns or other
server side defaults. MS-SQL does not
allow the usage of OUTPUT INSERTED on tables that have triggers.
To disable the usage of OUTPUT INSERTED on a per-table basis,
specify implicit_returning=False
for each Table
which has triggers:
Table(
"mytable",
metadata,
Column("id", Integer, primary_key=True),
# ...,
implicit_returning=False,
)
Declarative form:
class MyClass(Base):
# ...
__table_args__ = {"implicit_returning": False}
行数支持/ORM 版本控制¶
Rowcount Support / ORM Versioning
SQL Server 驱动程序可能在返回 UPDATE 或 DELETE 语句的更新行数方面存在限制。
截至目前,PyODBC 驱动程序在使用 OUTPUT INSERTED 时无法返回行数。因此,SQLAlchemy 的早期版本在依赖准确行数以匹配版本号与匹配行数的功能(如 “ORM 版本控制” 功能)上存在限制。
SQLAlchemy 2.0 现在通过手动检索这些特定用例的 “rowcount” 来解决这个问题,方法是通过计算 RETURNING 中返回的行数;因此,尽管驱动程序仍然存在此限制,但 ORM 版本控制功能不再受其影响。自 SQLAlchemy 2.0.5 起,pyodbc 驱动程序已完全恢复 ORM 版本控制支持。
在 2.0.5 版本发生变更: 恢复了对 pyodbc 驱动程序的 ORM 版本控制支持。 之前,在 ORM 刷新期间会发出警告,指示版本控制不受支持。
The SQL Server drivers may have limited ability to return the number of rows updated from an UPDATE or DELETE statement.
As of this writing, the PyODBC driver is not able to return a rowcount when OUTPUT INSERTED is used. Previous versions of SQLAlchemy therefore had limitations for features such as the “ORM Versioning” feature that relies upon accurate rowcounts in order to match version numbers with matched rows.
SQLAlchemy 2.0 now retrieves the “rowcount” manually for these particular use cases based on counting the rows that arrived back within RETURNING; so while the driver still has this limitation, the ORM Versioning feature is no longer impacted by it. As of SQLAlchemy 2.0.5, ORM versioning has been fully re-enabled for the pyodbc driver.
在 2.0.5 版本发生变更: ORM versioning support is restored for the pyodbc driver. Previously, a warning would be emitted during ORM flush that versioning was not supported.
启用快照隔离¶
Enabling Snapshot Isolation
SQL Server 有一个默认的事务隔离模式,它会锁定整个表,并导致即使是轻度并发的应用程序也会有长时间持有的锁和频繁的死锁。建议为整个数据库启用快照隔离,以支持现代级别的并发性。这可以通过以下 SQL 提示中的 ALTER DATABASE 命令来实现:
ALTER DATABASE MyDatabase SET ALLOW_SNAPSHOT_ISOLATION ON
ALTER DATABASE MyDatabase SET READ_COMMITTED_SNAPSHOT ON
有关 SQL Server 快照隔离的背景信息,请参见 https://msdn.microsoft.com/en-us/library/ms175095.aspx。
SQL Server has a default transaction isolation mode that locks entire tables, and causes even mildly concurrent applications to have long held locks and frequent deadlocks. Enabling snapshot isolation for the database as a whole is recommended for modern levels of concurrency support. This is accomplished via the following ALTER DATABASE commands executed at the SQL prompt:
ALTER DATABASE MyDatabase SET ALLOW_SNAPSHOT_ISOLATION ON
ALTER DATABASE MyDatabase SET READ_COMMITTED_SNAPSHOT ON
Background on SQL Server snapshot isolation is available at https://msdn.microsoft.com/en-us/library/ms175095.aspx.
SQL Server SQL 构造¶
SQL Server SQL Constructs
Object Name | Description |
---|---|
try_cast(expression, type_) |
Produce a |
- function sqlalchemy.dialects.mssql.try_cast(expression: _ColumnExpressionOrLiteralArgument[Any], type_: _TypeEngineArgument[_T]) TryCast[_T] ¶
Produce a
TRY_CAST
expression for backends which support it; this is aCAST
which returns NULL for un-castable conversions.In SQLAlchemy, this construct is supported only by the SQL Server dialect, and will raise a
CompileError
if used on other included backends. However, third party backends may also support this construct.小技巧
As
try_cast()
originates from the SQL Server dialect, it’s importable both fromsqlalchemy.
as well as fromsqlalchemy.dialects.mssql
.try_cast()
returns an instance ofTryCast
and generally behaves similarly to theCast
construct; at the SQL level, the difference betweenCAST
andTRY_CAST
is thatTRY_CAST
returns NULL for an un-castable expression, such as attempting to cast a string"hi"
to an integer value.E.g.:
from sqlalchemy import select, try_cast, Numeric stmt = select(try_cast(product_table.c.unit_price, Numeric(10, 4)))
The above would render on Microsoft SQL Server as:
SELECT TRY_CAST (product_table.unit_price AS NUMERIC(10, 4)) FROM product_table
在 2.0.14 版本加入:
try_cast()
has been generalized from the SQL Server dialect into a general use construct that may be supported by additional dialects.
SQL Server 数据类型¶
SQL Server Data Types
与所有SQLAlchemy方言一样,所有已知对SQL Server有效的UPPERCASE类型都可以从顶级方言中导入,无论它们是来自 sqlalchemy.types
还是来自本地方言:
from sqlalchemy.dialects.mssql import (
BIGINT,
BINARY,
BIT,
CHAR,
DATE,
DATETIME,
DATETIME2,
DATETIMEOFFSET,
DECIMAL,
DOUBLE_PRECISION,
FLOAT,
IMAGE,
INTEGER,
JSON,
MONEY,
NCHAR,
NTEXT,
NUMERIC,
NVARCHAR,
REAL,
SMALLDATETIME,
SMALLINT,
SMALLMONEY,
SQL_VARIANT,
TEXT,
TIME,
TIMESTAMP,
TINYINT,
UNIQUEIDENTIFIER,
VARBINARY,
VARCHAR,
)
特定于SQL Server或具有SQL Server特定构造参数的类型如下:
As with all SQLAlchemy dialects, all UPPERCASE types that are known to be
valid with SQL server are importable from the top level dialect, whether
they originate from sqlalchemy.types
or from the local dialect:
from sqlalchemy.dialects.mssql import (
BIGINT,
BINARY,
BIT,
CHAR,
DATE,
DATETIME,
DATETIME2,
DATETIMEOFFSET,
DECIMAL,
DOUBLE_PRECISION,
FLOAT,
IMAGE,
INTEGER,
JSON,
MONEY,
NCHAR,
NTEXT,
NUMERIC,
NVARCHAR,
REAL,
SMALLDATETIME,
SMALLINT,
SMALLMONEY,
SQL_VARIANT,
TEXT,
TIME,
TIMESTAMP,
TINYINT,
UNIQUEIDENTIFIER,
VARBINARY,
VARCHAR,
)
Types which are specific to SQL Server, or have SQL Server-specific construction arguments, are as follows:
Object Name | Description |
---|---|
MSSQL BIT type. |
|
the SQL Server DOUBLE PRECISION datatype. |
|
MSSQL JSON type. |
|
MSSQL NTEXT type, for variable-length unicode text up to 2^30 characters. |
|
the SQL Server REAL datatype. |
|
Implement the SQL Server ROWVERSION type. |
|
Implement the SQL Server TIMESTAMP type. |
|
MSSQL XML type. |
- class sqlalchemy.dialects.mssql.BIT¶
MSSQL BIT type.
Both pyodbc and pymssql return values from BIT columns as Python <class ‘bool’> so just subclass Boolean.
Members
Class signature
class
sqlalchemy.dialects.mssql.BIT
(sqlalchemy.types.Boolean
)-
method
sqlalchemy.dialects.mssql.BIT.
__init__(create_constraint: bool = False, name: str | None = None, _create_events: bool = True, _adapted_from: SchemaType | None = None)¶ inherited from the
sqlalchemy.types.Boolean.__init__
method ofBoolean
Construct a Boolean.
- 参数:
create_constraint¶ –
defaults to False. If the boolean is generated as an int/smallint, also create a CHECK constraint on the table that ensures 1 or 0 as a value.
备注
it is strongly recommended that the CHECK constraint have an explicit name in order to support schema-management concerns. This can be established either by setting the
Boolean.name
parameter or by setting up an appropriate naming convention; see 配置约束命名约定 for background.在 1.4 版本发生变更: - this flag now defaults to False, meaning no CHECK constraint is generated for a non-native enumerated type.
name¶ – if a CHECK constraint is generated, specify the name of the constraint.
-
method
- class sqlalchemy.dialects.mssql.CHAR
The SQL CHAR type.
Class signature
class
sqlalchemy.dialects.mssql.CHAR
(sqlalchemy.types.String
)-
method
sqlalchemy.dialects.mssql.CHAR.
__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.mssql.DATETIME2¶
Class signature
class
sqlalchemy.dialects.mssql.DATETIME2
(sqlalchemy.dialects.mssql.base._DateTimeBase
,sqlalchemy.types.DateTime
)
- class sqlalchemy.dialects.mssql.DATETIMEOFFSET¶
Class signature
class
sqlalchemy.dialects.mssql.DATETIMEOFFSET
(sqlalchemy.dialects.mssql.base._DateTimeBase
,sqlalchemy.types.DateTime
)
- class sqlalchemy.dialects.mssql.DOUBLE_PRECISION¶
the SQL Server DOUBLE PRECISION datatype.
在 2.0.11 版本加入.
Class signature
class
sqlalchemy.dialects.mssql.DOUBLE_PRECISION
(sqlalchemy.types.DOUBLE_PRECISION
)
- class sqlalchemy.dialects.mssql.IMAGE¶
Members
Class signature
class
sqlalchemy.dialects.mssql.IMAGE
(sqlalchemy.types.LargeBinary
)-
method
sqlalchemy.dialects.mssql.IMAGE.
__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.mssql.JSON¶
MSSQL JSON type.
MSSQL supports JSON-formatted data as of SQL Server 2016.
The
JSON
datatype at the DDL level will represent the datatype asNVARCHAR(max)
, but provides for JSON-level comparison functions as well as Python coercion behavior.JSON
is used automatically whenever the baseJSON
datatype is used against a SQL Server backend.参见
JSON
- main documentation for the generic cross-platform JSON datatype.The
JSON
type supports persistence of JSON values as well as the core index operations provided byJSON
datatype, by adapting the operations to render theJSON_VALUE
orJSON_QUERY
functions at the database level.The SQL Server
JSON
type necessarily makes use of theJSON_QUERY
andJSON_VALUE
functions when querying for elements of a JSON object. These two functions have a major restriction in that they are mutually exclusive based on the type of object to be returned. TheJSON_QUERY
function only returns a JSON dictionary or list, but not an individual string, numeric, or boolean element; theJSON_VALUE
function only returns an individual string, numeric, or boolean element. both functions either return NULL or raise an error if they are not used against the correct expected value.To handle this awkward requirement, indexed access rules are as follows:
When extracting a sub element from a JSON that is itself a JSON dictionary or list, the
Comparator.as_json()
accessor should be used:stmt = select(data_table.c.data["some key"].as_json()).where( data_table.c.data["some key"].as_json() == {"sub": "structure"} )
When extracting a sub element from a JSON that is a plain boolean, string, integer, or float, use the appropriate method among
Comparator.as_boolean()
,Comparator.as_string()
,Comparator.as_integer()
,Comparator.as_float()
:stmt = select(data_table.c.data["some key"].as_string()).where( data_table.c.data["some key"].as_string() == "some string" )
在 1.4 版本加入.
Members
Class signature
class
sqlalchemy.dialects.mssql.JSON
(sqlalchemy.types.JSON
)-
method
sqlalchemy.dialects.mssql.JSON.
__init__(none_as_null: bool = False)¶ inherited from the
sqlalchemy.types.JSON.__init__
method ofJSON
Construct a
JSON
type.- 参数:
none_as_null=False¶ –
if True, persist the value
None
as a SQL NULL value, not the JSON encoding ofnull
. Note that when this flag is False, thenull()
construct can still be used to persist a NULL value, which may be passed directly as a parameter value that is specially interpreted by theJSON
type as SQL NULL:from sqlalchemy import null conn.execute(table.insert(), {"data": null()})
备注
JSON.none_as_null
does not apply to the values passed toColumn.default
andColumn.server_default
; a value ofNone
passed for these parameters means “no default present”.Additionally, when used in SQL comparison expressions, the Python value
None
continues to refer to SQL null, and not JSON NULL. TheJSON.none_as_null
flag refers explicitly to the persistence of the value within an INSERT or UPDATE statement. TheJSON.NULL
value should be used for SQL expressions that wish to compare to JSON null.参见
- class sqlalchemy.dialects.mssql.MONEY¶
Class signature
class
sqlalchemy.dialects.mssql.MONEY
(sqlalchemy.types.TypeEngine
)
- class sqlalchemy.dialects.mssql.NCHAR
The SQL NCHAR type.
Class signature
class
sqlalchemy.dialects.mssql.NCHAR
(sqlalchemy.types.Unicode
)-
method
sqlalchemy.dialects.mssql.NCHAR.
__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.mssql.NTEXT¶
MSSQL NTEXT type, for variable-length unicode text up to 2^30 characters.
Members
Class signature
class
sqlalchemy.dialects.mssql.NTEXT
(sqlalchemy.types.UnicodeText
)-
method
sqlalchemy.dialects.mssql.NTEXT.
__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.mssql.NVARCHAR
The SQL NVARCHAR type.
Class signature
class
sqlalchemy.dialects.mssql.NVARCHAR
(sqlalchemy.types.Unicode
)-
method
sqlalchemy.dialects.mssql.NVARCHAR.
__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.mssql.REAL¶
the SQL Server REAL datatype.
Class signature
class
sqlalchemy.dialects.mssql.REAL
(sqlalchemy.types.REAL
)
- class sqlalchemy.dialects.mssql.ROWVERSION¶
Implement the SQL Server ROWVERSION type.
The ROWVERSION datatype is a SQL Server synonym for the TIMESTAMP datatype, however current SQL Server documentation suggests using ROWVERSION for new datatypes going forward.
The ROWVERSION datatype does not reflect (e.g. introspect) from the database as itself; the returned datatype will be
TIMESTAMP
.This is a read-only datatype that does not support INSERT of values.
参见
Members
Class signature
class
sqlalchemy.dialects.mssql.ROWVERSION
(sqlalchemy.dialects.mssql.base.TIMESTAMP
)-
method
sqlalchemy.dialects.mssql.ROWVERSION.
__init__(convert_int=False)¶ inherited from the
sqlalchemy.dialects.mssql.base.TIMESTAMP.__init__
method ofTIMESTAMP
Construct a TIMESTAMP or ROWVERSION type.
- 参数:
convert_int¶ – if True, binary integer values will be converted to integers on read.
-
method
- class sqlalchemy.dialects.mssql.SMALLDATETIME¶
Members
Class signature
class
sqlalchemy.dialects.mssql.SMALLDATETIME
(sqlalchemy.dialects.mssql.base._DateTimeBase
,sqlalchemy.types.DateTime
)-
method
sqlalchemy.dialects.mssql.SMALLDATETIME.
__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.mssql.SMALLMONEY¶
Class signature
class
sqlalchemy.dialects.mssql.SMALLMONEY
(sqlalchemy.types.TypeEngine
)
- class sqlalchemy.dialects.mssql.SQL_VARIANT¶
Class signature
class
sqlalchemy.dialects.mssql.SQL_VARIANT
(sqlalchemy.types.TypeEngine
)
- class sqlalchemy.dialects.mssql.TEXT
The SQL TEXT type.
Class signature
class
sqlalchemy.dialects.mssql.TEXT
(sqlalchemy.types.Text
)-
method
sqlalchemy.dialects.mssql.TEXT.
__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.mssql.TIME¶
Class signature
class
sqlalchemy.dialects.mssql.TIME
(sqlalchemy.types.TIME
)
- class sqlalchemy.dialects.mssql.TIMESTAMP¶
Implement the SQL Server TIMESTAMP type.
Note this is completely different than the SQL Standard TIMESTAMP type, which is not supported by SQL Server. It is a read-only datatype that does not support INSERT of values.
参见
Members
Class signature
class
sqlalchemy.dialects.mssql.TIMESTAMP
(sqlalchemy.types._Binary
)-
method
sqlalchemy.dialects.mssql.TIMESTAMP.
__init__(convert_int=False)¶ Construct a TIMESTAMP or ROWVERSION type.
- 参数:
convert_int¶ – if True, binary integer values will be converted to integers on read.
-
method
- class sqlalchemy.dialects.mssql.TINYINT¶
Class signature
class
sqlalchemy.dialects.mssql.TINYINT
(sqlalchemy.types.Integer
)
- class sqlalchemy.dialects.mssql.UNIQUEIDENTIFIER¶
Members
Class signature
class
sqlalchemy.dialects.mssql.UNIQUEIDENTIFIER
(sqlalchemy.types.Uuid
)-
method
sqlalchemy.dialects.mssql.UNIQUEIDENTIFIER.
__init__(as_uuid: bool = True)¶ Construct a
UNIQUEIDENTIFIER
type.- 参数:
as_uuid=True¶ –
if True, values will be interpreted as Python uuid objects, converting to/from string via the DBAPI.
在 2.0 版本发生变更: Added direct “uuid” support to the
UNIQUEIDENTIFIER
datatype; uuid interpretation defaults toTrue
.
-
method
- class sqlalchemy.dialects.mssql.VARBINARY
The MSSQL VARBINARY type.
This type adds additional features to the core
VARBINARY
type, including “deprecate_large_types” mode where eitherVARBINARY(max)
or IMAGE is rendered, as well as the SQL ServerFILESTREAM
option.参见
Class signature
class
sqlalchemy.dialects.mssql.VARBINARY
(sqlalchemy.types.VARBINARY
,sqlalchemy.types.LargeBinary
)-
method
sqlalchemy.dialects.mssql.VARBINARY.
__init__(length=None, filestream=False) Construct a VARBINARY type.
-
method
- class sqlalchemy.dialects.mssql.VARCHAR
The SQL VARCHAR type.
Class signature
class
sqlalchemy.dialects.mssql.VARCHAR
(sqlalchemy.types.String
)-
method
sqlalchemy.dialects.mssql.VARCHAR.
__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.mssql.XML¶
MSSQL XML type.
This is a placeholder type for reflection purposes that does not include any Python-side datatype support. It also does not currently support additional arguments, such as “CONTENT”, “DOCUMENT”, “xml_schema_collection”.
Members
Class signature
-
method
sqlalchemy.dialects.mssql.XML.
__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
PyODBC¶
Support for the Microsoft SQL Server database via the PyODBC driver.
DBAPI¶
Documentation and download information (if applicable) for PyODBC is available at: https://pypi.org/project/pyodbc/
Connecting¶
Connect String:
mssql+pyodbc://<username>:<password>@<dsnname>
连接到 PyODBC¶
Connecting to PyODBC
此处的 URL 将被转换为 PyODBC 连接字符串,如 ConnectionStrings 中所述。
The URL here is to be translated to PyODBC connection strings, as detailed in ConnectionStrings.
DSN 连接¶
DSN Connections
ODBC 中的 DSN 连接意味着客户端计算机上配置了一个预先存在的 ODBC 数据源。应用程序随后指定该数据源的名称,该名称包含诸如使用的特定 ODBC 驱动程序以及数据库的网络地址等详细信息。假设客户端已配置数据源,基本的基于 DSN 的连接如下所示:
engine = create_engine("mssql+pyodbc://scott:tiger@some_dsn")
上述代码将把以下连接字符串传递给 PyODBC:
DSN=some_dsn;UID=scott;PWD=tiger
如果省略用户名和密码,DSN 形式也会将 Trusted_Connection=yes
指令添加到 ODBC 字符串中。
A DSN connection in ODBC means that a pre-existing ODBC datasource is configured on the client machine. The application then specifies the name of this datasource, which encompasses details such as the specific ODBC driver in use as well as the network address of the database. Assuming a datasource is configured on the client, a basic DSN-based connection looks like:
engine = create_engine("mssql+pyodbc://scott:tiger@some_dsn")
Which above, will pass the following connection string to PyODBC:
DSN=some_dsn;UID=scott;PWD=tiger
If the username and password are omitted, the DSN form will also add
the Trusted_Connection=yes
directive to the ODBC string.
主机名连接¶
Hostname Connections
PyODBC 也支持基于主机名的连接。这些连接通常比 DSN 更容易使用,另外,它们的一个优点是可以在 URL 中本地指定要连接的具体数据库名称,而不是将其作为数据源配置的一部分固定。
使用主机名连接时,必须在 URL 的查询参数中指定驱动程序名称。由于这些名称通常包含空格,因此名称必须进行 URL 编码,即使用加号代替空格:
engine = create_engine(
"mssql+pyodbc://scott:tiger@myhost:port/databasename?driver=ODBC+Driver+17+for+SQL+Server"
)
driver
关键字对 pyodbc 方言至关重要,必须小写书写。
查询字符串中传递的任何其他名称都会传递到 pyodbc 连接字符串中,如 authentication
、TrustServerCertificate
等。多个关键字参数必须用和号(&
)分隔;当生成内部 pyodbc 连接字符串时,这些参数会被转换为分号:
e = create_engine(
"mssql+pyodbc://scott:tiger@mssql2017:1433/test?"
"driver=ODBC+Driver+18+for+SQL+Server&TrustServerCertificate=yes"
"&authentication=ActiveDirectoryIntegrated"
)
等效的 URL 可以使用 URL
构建:
from sqlalchemy.engine import URL
connection_url = URL.create(
"mssql+pyodbc",
username="scott",
password="tiger",
host="mssql2017",
port=1433,
database="test",
query={
"driver": "ODBC Driver 18 for SQL Server",
"TrustServerCertificate": "yes",
"authentication": "ActiveDirectoryIntegrated",
},
)
Hostname-based connections are also supported by pyodbc. These are often easier to use than a DSN and have the additional advantage that the specific database name to connect towards may be specified locally in the URL, rather than it being fixed as part of a datasource configuration.
When using a hostname connection, the driver name must also be specified in the query parameters of the URL. As these names usually have spaces in them, the name must be URL encoded which means using plus signs for spaces:
engine = create_engine(
"mssql+pyodbc://scott:tiger@myhost:port/databasename?driver=ODBC+Driver+17+for+SQL+Server"
)
The driver
keyword is significant to the pyodbc dialect and must be
specified in lowercase.
Any other names passed in the query string are passed through in the pyodbc
connect string, such as authentication
, TrustServerCertificate
, etc.
Multiple keyword arguments must be separated by an ampersand (&
); these
will be translated to semicolons when the pyodbc connect string is generated
internally:
e = create_engine(
"mssql+pyodbc://scott:tiger@mssql2017:1433/test?"
"driver=ODBC+Driver+18+for+SQL+Server&TrustServerCertificate=yes"
"&authentication=ActiveDirectoryIntegrated"
)
The equivalent URL can be constructed using URL
:
from sqlalchemy.engine import URL
connection_url = URL.create(
"mssql+pyodbc",
username="scott",
password="tiger",
host="mssql2017",
port=1433,
database="test",
query={
"driver": "ODBC Driver 18 for SQL Server",
"TrustServerCertificate": "yes",
"authentication": "ActiveDirectoryIntegrated",
},
)
传递精确的 Pyodbc 字符串¶
Pass through exact Pyodbc string
也可以直接发送 PyODBC 格式的连接字符串,正如在 PyODBC 文档 中所指定,使用参数 odbc_connect
。使用 URL
对象可以简化此操作:
from sqlalchemy.engine import URL
connection_string = "DRIVER={SQL Server Native Client 10.0};SERVER=dagger;DATABASE=test;UID=user;PWD=password"
connection_url = URL.create(
"mssql+pyodbc", query={"odbc_connect": connection_string}
)
engine = create_engine(connection_url)
A PyODBC connection string can also be sent in pyodbc’s format directly, as
specified in the PyODBC documentation,
using the parameter odbc_connect
. A URL
object
can help make this easier:
from sqlalchemy.engine import URL
connection_string = "DRIVER={SQL Server Native Client 10.0};SERVER=dagger;DATABASE=test;UID=user;PWD=password"
connection_url = URL.create(
"mssql+pyodbc", query={"odbc_connect": connection_string}
)
engine = create_engine(connection_url)
使用访问令牌连接到数据库¶
Connecting to databases with access tokens
一些数据库服务器仅接受访问令牌进行登录。例如,SQL Server 允许使用 Azure Active Directory 令牌连接到数据库。这需要使用 azure-identity
库创建凭证对象。有关身份验证步骤的更多信息,请参见 Microsoft 文档。
获取引擎后,每次请求连接时需要将凭证发送给 pyodbc.connect
。一种方法是在引擎上设置事件监听器,将凭证令牌添加到方言的连接调用中。这在 生成动态身份验证令牌 中有更广泛的讨论。对于 SQL Server,凭证作为 ODBC 连接属性传递,数据结构 由 Microsoft 描述。
以下代码片段将创建一个使用 Azure 凭证连接到 Azure SQL 数据库的引擎:
import struct
from sqlalchemy import create_engine, event
from sqlalchemy.engine.url import URL
from azure import identity
# 访问令牌的连接选项,定义在 msodbcsql.h 中
SQL_COPT_SS_ACCESS_TOKEN = 1256
TOKEN_URL = "https://database.windows.net/" # 任何 Azure SQL 数据库的令牌 URL
connection_string = "mssql+pyodbc://@my-server.database.windows.net/myDb?driver=ODBC+Driver+17+for+SQL+Server"
engine = create_engine(connection_string)
azure_credentials = identity.DefaultAzureCredential()
@event.listens_for(engine, "do_connect")
def provide_token(dialect, conn_rec, cargs, cparams):
# 删除 SQLAlchemy 添加的 "Trusted_Connection" 参数
cargs[0] = cargs[0].replace(";Trusted_Connection=Yes", "")
# 创建令牌凭证
raw_token = azure_credentials.get_token(TOKEN_URL).token.encode(
"utf-16-le"
)
token_struct = struct.pack(
f"<I{len(raw_token)}s", len(raw_token), raw_token
)
# 将其应用于关键字参数
cparams["attrs_before"] = {SQL_COPT_SS_ACCESS_TOKEN: token_struct}
小技巧
Trusted_Connection
令牌当前由 SQLAlchemy pyodbc 方言在没有用户名或密码时添加。根据 Microsoft 的
Azure 访问令牌文档,
需要删除它,说明当使用访问令牌时,连接字符串不能包含 UID
、PWD
、Authentication
或 Trusted_Connection
参数。
Some database servers are set up to only accept access tokens for login. For
example, SQL Server allows the use of Azure Active Directory tokens to connect
to databases. This requires creating a credential object using the
azure-identity
library. More information about the authentication step can be
found in Microsoft’s documentation.
After getting an engine, the credentials need to be sent to pyodbc.connect
each time a connection is requested. One way to do this is to set up an event
listener on the engine that adds the credential token to the dialect’s connect
call. This is discussed more generally in 生成动态身份验证令牌. For
SQL Server in particular, this is passed as an ODBC connection attribute with
a data structure described by Microsoft.
The following code snippet will create an engine that connects to an Azure SQL database using Azure credentials:
import struct
from sqlalchemy import create_engine, event
from sqlalchemy.engine.url import URL
from azure import identity
# Connection option for access tokens, as defined in msodbcsql.h
SQL_COPT_SS_ACCESS_TOKEN = 1256
TOKEN_URL = "https://database.windows.net/" # The token URL for any Azure SQL database
connection_string = "mssql+pyodbc://@my-server.database.windows.net/myDb?driver=ODBC+Driver+17+for+SQL+Server"
engine = create_engine(connection_string)
azure_credentials = identity.DefaultAzureCredential()
@event.listens_for(engine, "do_connect")
def provide_token(dialect, conn_rec, cargs, cparams):
# remove the "Trusted_Connection" parameter that SQLAlchemy adds
cargs[0] = cargs[0].replace(";Trusted_Connection=Yes", "")
# create token credential
raw_token = azure_credentials.get_token(TOKEN_URL).token.encode(
"utf-16-le"
)
token_struct = struct.pack(
f"<I{len(raw_token)}s", len(raw_token), raw_token
)
# apply it to keyword arguments
cparams["attrs_before"] = {SQL_COPT_SS_ACCESS_TOKEN: token_struct}
小技巧
The Trusted_Connection
token is currently added by the SQLAlchemy
pyodbc dialect when no username or password is present. This needs
to be removed per Microsoft’s
documentation for Azure access tokens,
stating that a connection string when using an access token must not contain
UID
, PWD
, Authentication
or Trusted_Connection
parameters.
避免 Azure Synapse Analytics 上出现与事务相关的异常¶
Avoiding transaction-related exceptions on Azure Synapse Analytics
Azure Synapse Analytics 在事务处理方面与普通 SQL Server 有显著差异;在某些情况下,Synapse 中事务内部的错误可能导致该事务在服务器端被任意中止,这会导致 DBAPI 的 .rollback()
方法(以及 .commit()
)失败。该问题打破了 DBAPI 的常规契约,即在没有事务的情况下允许 .rollback()
静默通过,因为驱动程序不会预期这种情况。该问题的症状是在某些操作失败后尝试执行 .rollback()
时抛出类似 ‘No corresponding transaction found. (111214)’ 的异常。
可以通过将 ignore_no_transaction_on_rollback=True
参数传递给 SQL Server 方言,并使用 create_engine()
函数来处理此特定情况,如下所示:
engine = create_engine(
connection_url, ignore_no_transaction_on_rollback=True
)
使用上述参数,方言将在 connection.rollback()
期间捕获 ProgrammingError
异常,如果错误消息包含代码 111214
,则会发出警告,但不会抛出异常。
在 1.4.40 版本加入: 增加了 ignore_no_transaction_on_rollback=True
参数。
Azure Synapse Analytics has a significant difference in its transaction
handling compared to plain SQL Server; in some cases an error within a Synapse
transaction can cause it to be arbitrarily terminated on the server side, which
then causes the DBAPI .rollback()
method (as well as .commit()
) to
fail. The issue prevents the usual DBAPI contract of allowing .rollback()
to pass silently if no transaction is present as the driver does not expect
this condition. The symptom of this failure is an exception with a message
resembling ‘No corresponding transaction found. (111214)’ when attempting to
emit a .rollback()
after an operation had a failure of some kind.
This specific case can be handled by passing ignore_no_transaction_on_rollback=True
to
the SQL Server dialect via the create_engine()
function as follows:
engine = create_engine(
connection_url, ignore_no_transaction_on_rollback=True
)
Using the above parameter, the dialect will catch ProgrammingError
exceptions raised during connection.rollback()
and emit a warning
if the error message contains code 111214
, however will not raise
an exception.
在 1.4.40 版本加入: Added the
ignore_no_transaction_on_rollback=True
parameter.
为 Azure SQL 数据仓库 (DW) 连接启用自动提交¶
Enable autocommit for Azure SQL Data Warehouse (DW) connections
Azure SQL Data Warehouse 不支持事务,这可能会导致 SQLAlchemy 的“自动启动事务”(autobegin)行为(以及隐式提交/回滚)出现问题。可以通过在 pyodbc 和 engine 层都启用自动提交来避免这些问题:
connection_url = sa.engine.URL.create(
"mssql+pyodbc",
username="scott",
password="tiger",
host="dw.azure.example.com",
database="mydb",
query={
"driver": "ODBC Driver 17 for SQL Server",
"autocommit": "True",
},
)
engine = create_engine(connection_url).execution_options(
isolation_level="AUTOCOMMIT"
)
Azure SQL Data Warehouse does not support transactions, and that can cause problems with SQLAlchemy’s “autobegin” (and implicit commit/rollback) behavior. We can avoid these problems by enabling autocommit at both the pyodbc and engine levels:
connection_url = sa.engine.URL.create(
"mssql+pyodbc",
username="scott",
password="tiger",
host="dw.azure.example.com",
database="mydb",
query={
"driver": "ODBC Driver 17 for SQL Server",
"autocommit": "True",
},
)
engine = create_engine(connection_url).execution_options(
isolation_level="AUTOCOMMIT"
)
避免以 TEXT/NTEXT 格式发送大型字符串参数¶
Avoiding sending large string parameters as TEXT/NTEXT
出于历史原因,Microsoft 的 SQL Server ODBC 驱动程序默认会将长字符串参数(超过 4000 个 SBCS 字符或 2000 个 Unicode 字符)作为 TEXT/NTEXT 类型发送。TEXT 和 NTEXT 类型已被弃用多年,并开始在新版 SQL Server/Azure 中引发兼容性问题。有关示例,请参见 此问题。
从 SQL Server 的 ODBC Driver 18 开始,可以通过连接字符串参数 LongAsMax=Yes
覆盖这一旧有行为,将长字符串作为 varchar(max)/nvarchar(max) 传递:
connection_url = sa.engine.URL.create(
"mssql+pyodbc",
username="scott",
password="tiger",
host="mssqlserver.example.com",
database="mydb",
query={
"driver": "ODBC Driver 18 for SQL Server",
"LongAsMax": "Yes",
},
)
By default, for historical reasons, Microsoft’s ODBC drivers for SQL Server send long string parameters (greater than 4000 SBCS characters or 2000 Unicode characters) as TEXT/NTEXT values. TEXT and NTEXT have been deprecated for many years and are starting to cause compatibility issues with newer versions of SQL_Server/Azure. For example, see this issue.
Starting with ODBC Driver 18 for SQL Server we can override the legacy
behavior and pass long strings as varchar(max)/nvarchar(max) using the
LongAsMax=Yes
connection string parameter:
connection_url = sa.engine.URL.create(
"mssql+pyodbc",
username="scott",
password="tiger",
host="mssqlserver.example.com",
database="mydb",
query={
"driver": "ODBC Driver 18 for SQL Server",
"LongAsMax": "Yes",
},
)
Pyodbc 池化/连接关闭行为¶
Pyodbc Pooling / connection close behavior
PyODBC 默认使用内部 连接池机制,这意味着连接的生命周期会比 SQLAlchemy 自身的连接更长。由于 SQLAlchemy 本身也有连接池机制,通常建议禁用 PyODBC 的连接池。该行为只能在 PyODBC 模块级别全局禁用,且必须在建立任何连接 之前 进行设置:
import pyodbc
pyodbc.pooling = False
# 在禁用连接池之前不要使用 engine
engine = create_engine("mssql+pyodbc://user:pass@dsn")
如果此变量保持默认值 True
,即使 SQLAlchemy 的 engine 彻底丢弃了连接或已被 dispose,应用程序仍会保持活动数据库连接。
参见
连接池 - 来自 PyODBC 文档。
PyODBC uses internal pooling by default, which means connections will be longer lived than they are within SQLAlchemy itself. As SQLAlchemy has its own pooling behavior, it is often preferable to disable this behavior. This behavior can only be disabled globally at the PyODBC module level, before any connections are made:
import pyodbc
pyodbc.pooling = False
# don't use the engine before pooling is set to False
engine = create_engine("mssql+pyodbc://user:pass@dsn")
If this variable is left at its default value of True
, the application
will continue to maintain active database connections, even when the
SQLAlchemy engine itself fully discards a connection or if the engine is
disposed.
参见
pooling - in the PyODBC documentation.
驱动程序/Unicode 支持¶
Driver / Unicode Support
PyODBC 在使用 Microsoft ODBC 驱动程序时表现最佳,特别是在 Python 2 和 Python 3 的 Unicode 支持方面。
在 Linux 或 OSX 上使用 FreeTDS ODBC 驱动程序配合 PyODBC 不推荐;在此方面历史上存在许多 Unicode 相关问题,尤其是在 Microsoft 尚未为 Linux 和 OSX 提供 ODBC 驱动时。现在 Microsoft 已为所有平台提供官方驱动,因此推荐在 PyODBC 中使用这些驱动。而 FreeTDS 在用于如 pymssql 这类非 ODBC 驱动时仍然非常实用。
PyODBC works best with Microsoft ODBC drivers, particularly in the area of Unicode support on both Python 2 and Python 3.
Using the FreeTDS ODBC drivers on Linux or OSX with PyODBC is not recommended; there have been historically many Unicode-related issues in this area, including before Microsoft offered ODBC drivers for Linux and OSX. Now that Microsoft offers drivers for all platforms, for PyODBC support these are recommended. FreeTDS remains relevant for non-ODBC drivers such as pymssql where it works very well.
行数支持¶
Rowcount Support
在 SQLAlchemy 2.0.5 中,ORM 的“版本控制行(versioned rows)”特性与 PyODBC 之间的限制已被修复。参见 行数支持/ORM 版本控制 中的说明。
Previous limitations with the SQLAlchemy ORM’s “versioned rows” feature with Pyodbc have been resolved as of SQLAlchemy 2.0.5. See the notes at 行数支持/ORM 版本控制.
快速执行模式¶
Fast Executemany Mode
PyODBC 驱动程序支持一种名为 “fast executemany” 的快速执行模式,该模式在使用 Microsoft ODBC 驱动程序时能极大减少 DBAPI executemany()
调用的往返次数,适用于 可全部装入内存的小批量数据 。该功能通过在 DBAPI 游标上设置 .fast_executemany
属性来启用。当使用 Microsoft ODBC 驱动程序时,SQLAlchemy 的 pyodbc SQL Server 方言支持通过 create_engine()
传递 fast_executemany
参数启用该功能:
engine = create_engine(
"mssql+pyodbc://scott:tiger@mssql2017:1433/test?driver=ODBC+Driver+17+for+SQL+Server",
fast_executemany=True,
)
在 2.0.9 版本发生变更: fast_executemany
参数现在在所有使用多组参数但不包含 RETURNING 的 INSERT 语句中生效。此前,在 SQLAlchemy 2.0 中,insertmanyvalues 特性曾导致即使指定了该参数,也在大多数情况下未被启用。
参见
fast executemany - 来自 github
The PyODBC driver includes support for a “fast executemany” mode of execution
which greatly reduces round trips for a DBAPI executemany()
call when using
Microsoft ODBC drivers, for limited size batches that fit in memory. The
feature is enabled by setting the attribute .fast_executemany
on the DBAPI
cursor when an executemany call is to be used. The SQLAlchemy PyODBC SQL
Server dialect supports this parameter by passing the
fast_executemany
parameter to
create_engine()
, when using the Microsoft ODBC driver only:
engine = create_engine(
"mssql+pyodbc://scott:tiger@mssql2017:1433/test?driver=ODBC+Driver+17+for+SQL+Server",
fast_executemany=True,
)
在 2.0.9 版本发生变更: - the fast_executemany
parameter now has its
intended effect of this PyODBC feature taking effect for all INSERT
statements that are executed with multiple parameter sets, which don’t
include RETURNING. Previously, SQLAlchemy 2.0’s insertmanyvalues
feature would cause fast_executemany
to not be used in most cases
even if specified.
参见
fast executemany - on github
设置输入大小支持¶
Setinputsizes Support
从 SQLAlchemy 2.0 起,除启用了 fast_executemany=True
的 cursor.executemany()
调用外,pyodbc 方言在执行所有语句时均使用 cursor.setinputsizes()
方法(假设未显式禁用 insertmanyvalues,则 INSERT 语句在任何情况下都不会触发 fast executemany)。
可以通过向 create_engine()
传递 use_setinputsizes=False
来禁用 cursor.setinputsizes()
的使用。
当 use_setinputsizes
保持默认值 True
时,可以通过 DialectEvents.do_setinputsizes()
钩子以编程方式自定义传递给 cursor.setinputsizes()
的每种类型的具体标记。请参阅该方法以获取使用示例。
在 2.0 版本发生变更: mssql+pyodbc 方言现在默认对所有语句执行使用 use_setinputsizes=True
,除了启用了 fast_executemany 的 cursor.executemany()
调用。该行为可通过向 create_engine()
传递 use_setinputsizes=False
来关闭。
As of version 2.0, the pyodbc cursor.setinputsizes()
method is used for
all statement executions, except for cursor.executemany()
calls when
fast_executemany=True where it is not supported (assuming
insertmanyvalues is kept enabled,
“fastexecutemany” will not take place for INSERT statements in any case).
The use of cursor.setinputsizes()
can be disabled by passing
use_setinputsizes=False
to create_engine()
.
When use_setinputsizes
is left at its default of True
, the
specific per-type symbols passed to cursor.setinputsizes()
can be
programmatically customized using the DialectEvents.do_setinputsizes()
hook. See that method for usage examples.
在 2.0 版本发生变更: The mssql+pyodbc dialect now defaults to using
use_setinputsizes=True
for all statement executions with the exception of
cursor.executemany() calls when fast_executemany=True. The behavior can
be turned off by passing use_setinputsizes=False
to
create_engine()
.
pymssql¶
Support for the Microsoft SQL Server database via the pymssql driver.
Connecting¶
Connect String:
mssql+pymssql://<username>:<password>@<freetds_name>/?charset=utf8
aioodbc¶
Support for the Microsoft SQL Server database via the aioodbc driver.
DBAPI¶
Documentation and download information (if applicable) for aioodbc is available at: https://pypi.org/project/aioodbc/
Connecting¶
Connect String:
mssql+aioodbc://<username>:<password>@<dsnname>
对 SQL Server 数据库的 asyncio 风格支持,使用的是 aioodbc 驱动,该驱动本质上是对 pyodbc 的线程封装。
在 2.0.23 版本加入.
新增了 mssql+aioodbc 方言,构建于 pyodbc 和通用 aio* 方言架构之上。
通过一个特殊的 asyncio 中介层,aioodbc 方言可作为 SQLAlchemy asyncio 扩展包的后端使用。
该驱动的大多数行为和注意事项与 SQL Server 所使用的 pyodbc 方言相同;一般背景信息请参见 PyODBC。
该方言通常应仅通过 create_async_engine()
引擎创建函数使用;其连接方式与 pyodbc 部分文档中描述的方式一致:
from sqlalchemy.ext.asyncio import create_async_engine
engine = create_async_engine(
"mssql+aioodbc://scott:tiger@mssql2017:1433/test?"
"driver=ODBC+Driver+18+for+SQL+Server&TrustServerCertificate=yes"
)
Support for the SQL Server database in asyncio style, using the aioodbc driver which itself is a thread-wrapper around pyodbc.
在 2.0.23 版本加入: Added the mssql+aioodbc dialect which builds on top of the pyodbc and general aio* dialect architecture.
Using a special asyncio mediation layer, the aioodbc dialect is usable as the backend for the SQLAlchemy asyncio extension package.
Most behaviors and caveats for this driver are the same as that of the pyodbc dialect used on SQL Server; see PyODBC for general background.
This dialect should normally be used only with the
create_async_engine()
engine creation function; connection
styles are otherwise equivalent to those documented in the pyodbc section:
from sqlalchemy.ext.asyncio import create_async_engine
engine = create_async_engine(
"mssql+aioodbc://scott:tiger@mssql2017:1433/test?"
"driver=ODBC+Driver+18+for+SQL+Server&TrustServerCertificate=yes"
)