SQLAlchemy 0.9 Documentation

Release: 0.9.4 | Release Date: March 28, 2014 | Download PDF
SQLAlchemy 0.9 Documentation » Dialects » Microsoft SQL Server

Microsoft SQL Server

Microsoft SQL Server

Support for the Microsoft SQL Server database.

DBAPI Support

The following dialect/DBAPI options are available. Please refer to individual DBAPI sections for connect information.

Auto Increment Behavior

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.

  • Support for SET IDENTITY_INSERT ON mode (automagic on / off for INSERT s)
  • Support for auto-fetching of @@IDENTITY/@@SCOPE_IDENTITY() on INSERT

Collation Support

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

New in version 0.8: Character collations are now part of the base string types.

LIMIT/OFFSET Support

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.

Nullability

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 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.

Clustered Index Support

The MSSQL dialect supports clustered indexes (and primary keys) via the mssql_clustered option. This option is available to Index, UniqueConstraint. and PrimaryKeyConstraint.

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).

New in version 0.8.

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),
        )

.. versionadded:: 0.9.2

MSSQL-Specific Index Options

In addition to clustering, the MSSQL dialect supports other special options for Index.

INCLUDE

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)

New in version 0.8.

Index ordering

Index ordering is available via functional expressions, such as:

Index("my_index", table.c.x.desc())

would render the index as CREATE INDEX my_index ON table (x DESC)

New in version 0.8.

Compatibility Levels

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 SQAlchemy may attempt to use T-SQL statements that are unable to be parsed by the database server.

Triggers

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().

Enabling Snapshot Isolation

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.

Known Issues

  • No support for more than one IDENTITY column per table
  • reflection of indexes does not work with versions older than SQL Server 2005

SQL Server Data Types

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:

class sqlalchemy.dialects.mssql.BIT

Bases: sqlalchemy.types.TypeEngine

__init__

x.__init__(...) initializes x; see help(type(x)) for signature

class sqlalchemy.dialects.mssql.CHAR(length=None, collation=None, convert_unicode=False, unicode_error=None, _warn_on_bytestring=False)

Bases: sqlalchemy.types.String

The SQL CHAR type.

__init__(length=None, collation=None, convert_unicode=False, unicode_error=None, _warn_on_bytestring=False)

Create a string-holding type.

Parameters:
  • length – optional, a length for the column for use in DDL and CAST expressions. May be safely omitted if no CREATE TABLE will be issued. Certain databases may require a length for use in DDL, and will raise an exception when the CREATE TABLE DDL is issued if a VARCHAR with no length is included. Whether the value is interpreted as bytes or characters is database specific.
  • collation

    Optional, a column-level collation for use in DDL and CAST expressions. Renders using the COLLATE keyword supported by SQLite, MySQL, and Postgresql. E.g.:

    >>> from sqlalchemy import cast, select, String
    >>> print select([cast('some string', String(collation='utf8'))])
    SELECT CAST(:param_1 AS VARCHAR COLLATE utf8) AS anon_1

    New in version 0.8: Added support for COLLATE to all string types.

  • convert_unicode

    When set to True, the String type will assume that input is to be passed as Python unicode objects, and results returned as Python unicode objects. If the DBAPI in use does not support Python unicode (which is fewer and fewer these days), SQLAlchemy will encode/decode the value, using the value of the encoding parameter passed to create_engine() as the encoding.

    When using a DBAPI that natively supports Python unicode objects, this flag generally does not need to be set. For columns that are explicitly intended to store non-ASCII data, the Unicode or UnicodeText types should be used regardless, which feature the same behavior of convert_unicode but also indicate an underlying column type that directly supports unicode, such as NVARCHAR.

    For the extremely rare case that Python unicode is to be encoded/decoded by SQLAlchemy on a backend that does natively support Python unicode, the value force can be passed here which will cause SQLAlchemy’s encode/decode services to be used unconditionally.

  • unicode_error – Optional, a method to use to handle Unicode conversion errors. Behaves like the errors keyword argument to the standard library’s string.decode() functions. This flag requires that convert_unicode is set to force - otherwise, SQLAlchemy is not guaranteed to handle the task of unicode conversion. Note that this flag adds significant performance overhead to row-fetching operations for backends that already return unicode objects natively (which most DBAPIs do). This flag should only be used as a last resort for reading strings from a column with varied or corrupted encodings.
class sqlalchemy.dialects.mssql.DATETIME2(precision=None, **kw)

Bases: sqlalchemy.dialects.mssql.base._DateTimeBase, sqlalchemy.types.DateTime

class sqlalchemy.dialects.mssql.DATETIMEOFFSET(precision=None, **kwargs)

Bases: sqlalchemy.types.TypeEngine

class sqlalchemy.dialects.mssql.IMAGE(length=None)

Bases: sqlalchemy.types.LargeBinary

__init__(length=None)

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.
class sqlalchemy.dialects.mssql.MONEY

Bases: sqlalchemy.types.TypeEngine

__init__

x.__init__(...) initializes x; see help(type(x)) for signature

class sqlalchemy.dialects.mssql.NCHAR(length=None, **kwargs)

Bases: sqlalchemy.types.Unicode

The SQL NCHAR type.

__init__(length=None, **kwargs)

Create a Unicode object.

Parameters are the same as that of String, with the exception that convert_unicode defaults to True.

class sqlalchemy.dialects.mssql.NTEXT(length=None, **kwargs)

Bases: sqlalchemy.types.UnicodeText

MSSQL NTEXT type, for variable-length unicode text up to 2^30 characters.

__init__(length=None, **kwargs)

Create a Unicode-converting Text type.

Parameters are the same as that of Text, with the exception that convert_unicode defaults to True.

class sqlalchemy.dialects.mssql.NVARCHAR(length=None, **kwargs)

Bases: sqlalchemy.types.Unicode

The SQL NVARCHAR type.

__init__(length=None, **kwargs)

Create a Unicode object.

Parameters are the same as that of String, with the exception that convert_unicode defaults to True.

class sqlalchemy.dialects.mssql.REAL(**kw)

Bases: sqlalchemy.types.REAL

class sqlalchemy.dialects.mssql.SMALLDATETIME(timezone=False)

Bases: sqlalchemy.dialects.mssql.base._DateTimeBase, sqlalchemy.types.DateTime

__init__(timezone=False)

Construct a new DateTime.

Parameters:timezone – boolean. If True, and supported by the backend, will produce ‘TIMESTAMP WITH TIMEZONE’. For backends that don’t support timezone aware timestamps, has no effect.
class sqlalchemy.dialects.mssql.SMALLMONEY

Bases: sqlalchemy.types.TypeEngine

__init__

x.__init__(...) initializes x; see help(type(x)) for signature

class sqlalchemy.dialects.mssql.SQL_VARIANT

Bases: sqlalchemy.types.TypeEngine

__init__

x.__init__(...) initializes x; see help(type(x)) for signature

class sqlalchemy.dialects.mssql.TEXT(length=None, collation=None, convert_unicode=False, unicode_error=None, _warn_on_bytestring=False)

Bases: sqlalchemy.types.Text

The SQL TEXT type.

__init__(length=None, collation=None, convert_unicode=False, unicode_error=None, _warn_on_bytestring=False)

Create a string-holding type.

Parameters:
  • length – optional, a length for the column for use in DDL and CAST expressions. May be safely omitted if no CREATE TABLE will be issued. Certain databases may require a length for use in DDL, and will raise an exception when the CREATE TABLE DDL is issued if a VARCHAR with no length is included. Whether the value is interpreted as bytes or characters is database specific.
  • collation

    Optional, a column-level collation for use in DDL and CAST expressions. Renders using the COLLATE keyword supported by SQLite, MySQL, and Postgresql. E.g.:

    >>> from sqlalchemy import cast, select, String
    >>> print select([cast('some string', String(collation='utf8'))])
    SELECT CAST(:param_1 AS VARCHAR COLLATE utf8) AS anon_1

    New in version 0.8: Added support for COLLATE to all string types.

  • convert_unicode

    When set to True, the String type will assume that input is to be passed as Python unicode objects, and results returned as Python unicode objects. If the DBAPI in use does not support Python unicode (which is fewer and fewer these days), SQLAlchemy will encode/decode the value, using the value of the encoding parameter passed to create_engine() as the encoding.

    When using a DBAPI that natively supports Python unicode objects, this flag generally does not need to be set. For columns that are explicitly intended to store non-ASCII data, the Unicode or UnicodeText types should be used regardless, which feature the same behavior of convert_unicode but also indicate an underlying column type that directly supports unicode, such as NVARCHAR.

    For the extremely rare case that Python unicode is to be encoded/decoded by SQLAlchemy on a backend that does natively support Python unicode, the value force can be passed here which will cause SQLAlchemy’s encode/decode services to be used unconditionally.

  • unicode_error – Optional, a method to use to handle Unicode conversion errors. Behaves like the errors keyword argument to the standard library’s string.decode() functions. This flag requires that convert_unicode is set to force - otherwise, SQLAlchemy is not guaranteed to handle the task of unicode conversion. Note that this flag adds significant performance overhead to row-fetching operations for backends that already return unicode objects natively (which most DBAPIs do). This flag should only be used as a last resort for reading strings from a column with varied or corrupted encodings.
class sqlalchemy.dialects.mssql.TIME(precision=None, **kwargs)

Bases: sqlalchemy.types.TIME

class sqlalchemy.dialects.mssql.TINYINT

Bases: sqlalchemy.types.Integer

__init__

x.__init__(...) initializes x; see help(type(x)) for signature

class sqlalchemy.dialects.mssql.UNIQUEIDENTIFIER

Bases: sqlalchemy.types.TypeEngine

__init__

x.__init__(...) initializes x; see help(type(x)) for signature

class sqlalchemy.dialects.mssql.VARCHAR(length=None, collation=None, convert_unicode=False, unicode_error=None, _warn_on_bytestring=False)

Bases: sqlalchemy.types.String

The SQL VARCHAR type.

__init__(length=None, collation=None, convert_unicode=False, unicode_error=None, _warn_on_bytestring=False)

Create a string-holding type.

Parameters:
  • length – optional, a length for the column for use in DDL and CAST expressions. May be safely omitted if no CREATE TABLE will be issued. Certain databases may require a length for use in DDL, and will raise an exception when the CREATE TABLE DDL is issued if a VARCHAR with no length is included. Whether the value is interpreted as bytes or characters is database specific.
  • collation

    Optional, a column-level collation for use in DDL and CAST expressions. Renders using the COLLATE keyword supported by SQLite, MySQL, and Postgresql. E.g.:

    >>> from sqlalchemy import cast, select, String
    >>> print select([cast('some string', String(collation='utf8'))])
    SELECT CAST(:param_1 AS VARCHAR COLLATE utf8) AS anon_1

    New in version 0.8: Added support for COLLATE to all string types.

  • convert_unicode

    When set to True, the String type will assume that input is to be passed as Python unicode objects, and results returned as Python unicode objects. If the DBAPI in use does not support Python unicode (which is fewer and fewer these days), SQLAlchemy will encode/decode the value, using the value of the encoding parameter passed to create_engine() as the encoding.

    When using a DBAPI that natively supports Python unicode objects, this flag generally does not need to be set. For columns that are explicitly intended to store non-ASCII data, the Unicode or UnicodeText types should be used regardless, which feature the same behavior of convert_unicode but also indicate an underlying column type that directly supports unicode, such as NVARCHAR.

    For the extremely rare case that Python unicode is to be encoded/decoded by SQLAlchemy on a backend that does natively support Python unicode, the value force can be passed here which will cause SQLAlchemy’s encode/decode services to be used unconditionally.

  • unicode_error – Optional, a method to use to handle Unicode conversion errors. Behaves like the errors keyword argument to the standard library’s string.decode() functions. This flag requires that convert_unicode is set to force - otherwise, SQLAlchemy is not guaranteed to handle the task of unicode conversion. Note that this flag adds significant performance overhead to row-fetching operations for backends that already return unicode objects natively (which most DBAPIs do). This flag should only be used as a last resort for reading strings from a column with varied or corrupted encodings.

PyODBC

Support for the Microsoft SQL Server database via the PyODBC driver.

DBAPI

Documentation and download information (if applicable) for PyODBC is available at: http://pypi.python.org/pypi/pyodbc/

Connecting

Connect String:

mssql+pyodbc://<username>:<password>@<dsnname>

Additional Connection Examples

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 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 which includes the port information using the comma syntax. 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 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
  • mssql+pyodbc://user:pass@host/db?driver=MyDriver - connects using a connection string that includes a custom ODBC driver name. This will create the following connection string:

    DRIVER={MyDriver};Server=host;Database=db;UID=user;PWD=pass

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'

Unicode Binds

The current state of PyODBC on a unix backend with FreeTDS and/or EasySoft is poor regarding unicode; different OS platforms and versions of UnixODBC versus IODBC versus FreeTDS/EasySoft versus PyODBC itself dramatically alter how strings are received. The PyODBC dialect attempts to use all the information it knows to determine whether or not a Python unicode literal can be passed directly to the PyODBC driver or not; while SQLAlchemy can encode these to bytestrings first, some users have reported that PyODBC mis-handles bytestrings for certain encodings and requires a Python unicode object, while the author has observed widespread cases where a Python unicode is completely misinterpreted by PyODBC, particularly when dealing with the information schema tables used in table reflection, and the value must first be encoded to a bytestring.

It is for this reason that whether or not unicode literals for bound parameters be sent to PyODBC can be controlled using the supports_unicode_binds parameter to create_engine(). When left at its default of None, the PyODBC dialect will use its best guess as to whether or not the driver deals with unicode literals well. When False, unicode literals will be encoded first, and when True unicode literals will be passed straight through. This is an interim flag that hopefully should not be needed when the unicode situation stabilizes for unix + PyODBC.

New in version 0.7.7: supports_unicode_binds parameter to create_engine().

mxODBC

Support for the Microsoft SQL Server database via the mxODBC driver.

DBAPI

Documentation and download information (if applicable) for mxODBC is available at: http://www.egenix.com/

Connecting

Connect String:

mssql+mxodbc://<username>:<password>@<dsnname>

Execution Modes

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 unconditionally use string-escaped parameters.

pymssql

Support for the Microsoft SQL Server database via the pymssql driver.

DBAPI

Documentation and download information (if applicable) for pymssql is available at: http://pymssql.org/

Connecting

Connect String:

mssql+pymssql://<username>:<password>@<freetds_name>?charset=utf8

pymssql is a Python module that provides a Python DBAPI interface around FreeTDS. Compatible builds are available for Linux, MacOSX and Windows platforms.

zxjdbc

Support for the Microsoft SQL Server database via the zxJDBC for Jython driver.

DBAPI

Drivers for this database are available at: http://jtds.sourceforge.net/

Connecting

Connect String:

mssql+zxjdbc://user:pass@host:port/dbname[?key=value&key=value...]

AdoDBAPI

Support for the Microsoft SQL Server database via the adodbapi driver.

DBAPI

Documentation and download information (if applicable) for adodbapi is available at: http://adodbapi.sourceforge.net/

Connecting

Connect String:

mssql+adodbapi://<username>:<password>@<dsnname>

Note

The adodbapi dialect is not implemented SQLAlchemy versions 0.6 and above at this time.