Support for the Microsoft SQL Server database.
See the individual driver sections below for details on connecting.
IDENTITY columns are supported by using SQLAlchemy schema.Sequence() objects. In other words:
from sqlalchemy import Table, Integer, Sequence, Column
Table('test', metadata,
Column('id', Integer,
Sequence('blah',100,10), primary_key=True),
Column('name', String(20))
).create(some_engine)
would yield:
CREATE TABLE test (
id INTEGER NOT NULL IDENTITY(100,10) PRIMARY KEY,
name VARCHAR(20) NULL,
)
Note that the start and increment values for sequences are optional and will default to 1,1.
Implicit autoincrement behavior works the same in MSSQL as it does in other dialects and results in an IDENTITY column.
MSSQL specific string types support a collation parameter that creates a column-level specific collation for the column. The collation parameter accepts a Windows Collation Name or a SQL Collation Name. Supported types are MSChar, MSNChar, MSString, MSNVarchar, MSText, and MSNText. For example:
from sqlalchemy.dialects.mssql 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
MSSQL has no support for the LIMIT or OFFSET keysowrds. LIMIT is supported directly through the TOP Transact SQL keyword:
select.limit
will yield:
SELECT TOP n
If using SQL Server 2005 or above, LIMIT with OFFSET support is available through the ROW_NUMBER OVER construct. For versions below 2005, LIMIT with OFFSET usage will fail.
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 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.
MSSQL supports the notion of setting compatibility levels at the database level. This allows, for instance, to run a database that is compatibile 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 compatibiility level information. Because of this, if running under a backwards compatibility mode SQAlchemy may attempt to use T-SQL statements that are unable to be parsed by the database server.
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}
This option can also be specified engine-wide using the implicit_returning=False argument on create_engine().
Not necessarily specific to SQLAlchemy, 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 http://msdn.microsoft.com/en-us/library/ms175095.aspx.
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, FLOAT, IMAGE, INTEGER, 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:
Bases: sqlalchemy.types.TypeEngine
Bases: sqlalchemy.dialects.mssql.base._StringType, sqlalchemy.types.CHAR
MSSQL CHAR type, for fixed-length non-Unicode data with a maximum of 8,000 characters.
Construct a CHAR.
Parameters: |
|
---|
Bases: sqlalchemy.dialects.mssql.base._DateTimeBase, sqlalchemy.types.DateTime
Bases: sqlalchemy.types.TypeEngine
Bases: sqlalchemy.types.LargeBinary
Construct a LargeBinary type.
Parameters: | length – optional, a length for the column for use in DDL statements, for those BLOB types that accept a length (i.e. MySQL). It does not produce a small BINARY/VARBINARY type - use the BINARY/VARBINARY types specifically for those. May be safely omitted if no CREATE TABLE will be issued. Certain databases may require a length for use in DDL, and will raise an exception when the CREATE TABLE DDL is issued. |
---|
Bases: sqlalchemy.types.TypeEngine
Bases: sqlalchemy.dialects.mssql.base._StringType, sqlalchemy.types.NCHAR
MSSQL NCHAR type.
For fixed-length unicode character data up to 4,000 characters.
Construct an NCHAR.
Parameters: |
|
---|
Bases: sqlalchemy.dialects.mssql.base._StringType, sqlalchemy.types.UnicodeText
MSSQL NTEXT type, for variable-length unicode text up to 2^30 characters.
Construct a NTEXT.
Parameters: | collation – Optional, a column-level collation for this string value. Accepts a Windows Collation Name or a SQL Collation Name. |
---|
Bases: sqlalchemy.dialects.mssql.base._StringType, sqlalchemy.types.NVARCHAR
MSSQL NVARCHAR type.
For variable-length unicode character data up to 4,000 characters.
Construct a NVARCHAR.
Parameters: |
|
---|
Bases: sqlalchemy.types.Float
A type for real numbers.
Bases: sqlalchemy.dialects.mssql.base._DateTimeBase, sqlalchemy.types.DateTime
Bases: sqlalchemy.types.TypeEngine
Bases: sqlalchemy.types.TypeEngine
Bases: sqlalchemy.dialects.mssql.base._StringType, sqlalchemy.types.TEXT
MSSQL TEXT type, for variable-length text up to 2^31 characters.
Construct a TEXT.
Parameters: | collation – Optional, a column-level collation for this string value. Accepts a Windows Collation Name or a SQL Collation Name. |
---|
Bases: sqlalchemy.types.TIME
Bases: sqlalchemy.types.Integer
Bases: sqlalchemy.types.TypeEngine
Bases: sqlalchemy.dialects.mssql.base._StringType, sqlalchemy.types.VARCHAR
MSSQL VARCHAR type, for variable-length non-Unicode data with a maximum of 8,000 characters.
Construct a VARCHAR.
Parameters: |
|
---|
Support for MS-SQL via pyodbc.
pyodbc is available at:
Examples of pyodbc connection string URLs:
mssql+pyodbc://mydsn - connects using the specified DSN named mydsn. The connection string that is created will appear like:
dsn=mydsn;Trusted_Connection=Yes
mssql+pyodbc://user:pass@mydsn - connects using the DSN named mydsn passing in the UID and PWD information. The connection string that is created will appear like:
dsn=mydsn;UID=user;PWD=pass
mssql+pyodbc://user:pass@mydsn/?LANGUAGE=us_english - connects using the DSN named mydsn passing in the UID and PWD information, plus the additional connection configuration option LANGUAGE. The connection string that is created will appear like:
dsn=mydsn;UID=user;PWD=pass;LANGUAGE=us_english
mssql+pyodbc://user:pass@host/db - connects using a connection string dynamically created that would appear like:
DRIVER={SQL Server};Server=host;Database=db;UID=user;PWD=pass
mssql+pyodbc://user:pass@host:123/db - connects using a connection string that is dynamically created, which also includes the port information using the comma syntax. If your connection string requires the port information to be passed as a port keyword see the next example. This will create the following connection string:
DRIVER={SQL Server};Server=host,123;Database=db;UID=user;PWD=pass
mssql+pyodbc://user:pass@host/db?port=123 - connects using a connection string that is dynamically created that includes the port information as a separate port keyword. This will create the following connection string:
DRIVER={SQL Server};Server=host;Database=db;UID=user;PWD=pass;port=123
If you require a connection string that is outside the options presented above, use the odbc_connect keyword to pass in a urlencoded connection string. What gets passed in will be urldecoded and passed directly.
For example:
mssql+pyodbc:///?odbc_connect=dsn%3Dmydsn%3BDatabase%3Ddb
would create the following connection string:
dsn=mydsn;Database=db
Encoding your connection string can be easily accomplished through the python shell. For example:
>>> import urllib
>>> urllib.quote_plus('dsn=mydsn;Database=db')
'dsn%3Dmydsn%3BDatabase%3Ddb'
Support for MS-SQL via mxODBC.
mxODBC is available at:
This was tested with mxODBC 3.1.2 and the SQL Server Native Client connected to MSSQL 2005 and 2008 Express Editions.
mxODBC features two styles of statement execution, using the cursor.execute() and cursor.executedirect() methods (the second being an extension to the DBAPI specification). The former makes use of a particular API call specific to the SQL Server Native Client ODBC driver known SQLDescribeParam, while the latter does not.
mxODBC apparently only makes repeated use of a single prepared statement when SQLDescribeParam is used. The advantage to prepared statement reuse is one of performance. The disadvantage is that SQLDescribeParam has a limited set of scenarios in which bind parameters are understood, including that they cannot be placed within the argument lists of function calls, anywhere outside the FROM, or even within subqueries within the FROM clause - making the usage of bind parameters within SELECT statements impossible for all but the most simplistic statements.
For this reason, the mxODBC dialect uses the “native” mode by default only for INSERT, UPDATE, and DELETE statements, and uses the escaped string mode for all other statements.
This behavior can be controlled via execution_options() using the native_odbc_execute flag with a value of True or False, where a value of True will unconditionally use native bind parameters and a value of False will uncondtionally use string-escaped parameters.
Support for the pymssql dialect.
This dialect supports pymssql 1.0 and greater.
pymssql is available at:
Sample connect string:
mssql+pymssql://<username>:<password>@<freetds_name>
Adding ”?charset=utf8” or similar will cause pymssql to return strings as Python unicode objects. This can potentially improve performance in some scenarios as decoding of strings is handled natively.
pymssql inherits a lot of limitations from FreeTDS, including:
Please consult the pymssql documentation for further information.
Support for the Microsoft SQL Server database via the zxjdbc JDBC connector.
Requires the jTDS driver, available from: http://jtds.sourceforge.net/
URLs are of the standard form of mssql+zxjdbc://user:pass@host:port/dbname[?key=value&key=value...].
Additional arguments which may be specified either as query string arguments on the URL, or as keyword arguments to create_engine() will be passed as Connection properties to the underlying JDBC driver.
The adodbapi dialect is not implemented for 0.6 at this time.