SQLAlchemy 0.7 Documentation

Release: 0.7.10 | Release Date: February 7, 2013 | Download PDF

MySQL

Support for the MySQL database.

Supported Versions and Features

SQLAlchemy supports MySQL starting with version 4.1 through modern releases. However, no heroic measures are taken to work around major missing SQL features - if your server version does not support sub-selects, for example, they won’t work in SQLAlchemy either.

See the official MySQL documentation for detailed information about features supported in any given server release.

Connecting

See the API documentation on individual drivers for details on connecting.

Connection Timeouts

MySQL features an automatic connection close behavior, for connections that have been idle for eight hours or more. To circumvent having this issue, use the pool_recycle option which controls the maximum age of any connection:

engine = create_engine('mysql+mysqldb://...', pool_recycle=3600)

Storage Engines

Most MySQL server installations have a default table type of MyISAM, a non-transactional table type. During a transaction, non-transactional storage engines do not participate and continue to store table changes in autocommit mode. For fully atomic transactions as well as support for foreign key constraints, all participating tables must use a transactional engine such as InnoDB, Falcon, SolidDB, PBXT, etc.

Storage engines can be elected when creating tables in SQLAlchemy by supplying a mysql_engine='whatever' to the Table constructor. Any MySQL table creation option can be specified in this syntax:

Table('mytable', metadata,
      Column('data', String(32)),
      mysql_engine='InnoDB',
      mysql_charset='utf8'
     )

See also

The InnoDB Storage Engine - on the MySQL website.

Case Sensitivity and Table Reflection

MySQL has inconsistent support for case-sensitive identifier names, basing support on specific details of the underlying operating system. However, it has been observed that no matter what case sensitivity behavior is present, the names of tables in foreign key declarations are always received from the database as all-lower case, making it impossible to accurately reflect a schema where inter-related tables use mixed-case identifier names.

Therefore it is strongly advised that table names be declared as all lower case both within SQLAlchemy as well as on the MySQL database itself, especially if database reflection features are to be used.

Transaction Isolation Level

create_engine() accepts an isolation_level parameter which results in the command SET SESSION TRANSACTION ISOLATION LEVEL <level> being invoked for every new connection. Valid values for this parameter are READ COMMITTED, READ UNCOMMITTED, REPEATABLE READ, and SERIALIZABLE:

engine = create_engine(
                "mysql://scott:tiger@localhost/test",
                isolation_level="READ UNCOMMITTED"
            )

New in version 0.7.6.

Keys

Not all MySQL storage engines support foreign keys. For MyISAM and similar engines, the information loaded by table reflection will not include foreign keys. For these tables, you may supply a ForeignKeyConstraint at reflection time:

Table('mytable', metadata,
      ForeignKeyConstraint(['other_id'], ['othertable.other_id']),
      autoload=True
     )

When creating tables, SQLAlchemy will automatically set AUTO_INCREMENT on an integer primary key column:

>>> t = Table('mytable', metadata,
...   Column('mytable_id', Integer, primary_key=True)
... )
>>> t.create()
CREATE TABLE mytable (
        id INTEGER NOT NULL AUTO_INCREMENT,
        PRIMARY KEY (id)
)

You can disable this behavior by supplying autoincrement=False to the Column. This flag can also be used to enable auto-increment on a secondary column in a multi-column key for some storage engines:

Table('mytable', metadata,
      Column('gid', Integer, primary_key=True, autoincrement=False),
      Column('id', Integer, primary_key=True)
     )

Ansi Quoting Style

MySQL features two varieties of identifier “quoting style”, one using backticks and the other using quotes, e.g. `some_identifier` vs. "some_identifier". All MySQL dialects detect which version is in use by checking the value of sql_mode when a connection is first established with a particular Engine. This quoting style comes into play when rendering table and column names as well as when reflecting existing database structures. The detection is entirely automatic and no special configuration is needed to use either quoting style.

Changed in version 0.6: detection of ANSI quoting style is entirely automatic, there’s no longer any end-user create_engine() options in this regard.

MySQL SQL Extensions

Many of the MySQL SQL extensions are handled through SQLAlchemy’s generic function and operator support:

table.select(table.c.password==func.md5('plaintext'))
table.select(table.c.username.op('regexp')('^[a-d]'))

And of course any valid MySQL statement can be executed as a string as well.

Some limited direct support for MySQL extensions to SQL is currently available.

  • SELECT pragma:

    select(..., prefixes=['HIGH_PRIORITY', 'SQL_SMALL_RESULT'])
  • UPDATE with LIMIT:

    update(..., mysql_limit=10)

rowcount Support

SQLAlchemy standardizes the DBAPI cursor.rowcount attribute to be the usual definition of “number of rows matched by an UPDATE or DELETE” statement. This is in contradiction to the default setting on most MySQL DBAPI drivers, which is “number of rows actually modified/deleted”. For this reason, the SQLAlchemy MySQL dialects always set the constants.CLIENT.FOUND_ROWS flag, or whatever is equivalent for the DBAPI in use, on connect, unless the flag value is overridden using DBAPI-specific options (such as client_flag for the MySQL-Python driver, found_rows for the OurSQL driver).

See also:

ResultProxy.rowcount

CAST Support

MySQL documents the CAST operator as available in version 4.0.2. When using the SQLAlchemy cast() function, SQLAlchemy will not render the CAST token on MySQL before this version, based on server version detection, instead rendering the internal expression directly.

CAST may still not be desirable on an early MySQL version post-4.0.2, as it didn’t add all datatype support until 4.1.1. If your application falls into this narrow area, the behavior of CAST can be controlled using the Custom SQL Constructs and Compilation Extension system, as per the recipe below:

from sqlalchemy.sql.expression import _Cast
from sqlalchemy.ext.compiler import compiles

@compiles(_Cast, 'mysql')
def _check_mysql_version(element, compiler, **kw):
    if compiler.dialect.server_version_info < (4, 1, 0):
        return compiler.process(element.clause, **kw)
    else:
        return compiler.visit_cast(element, **kw)

The above function, which only needs to be declared once within an application, overrides the compilation of the cast() construct to check for version 4.1.0 before fully rendering CAST; else the internal element of the construct is rendered directly.

MySQL Specific Index Options

MySQL-specific extensions to the Index construct are available.

Index Length

MySQL provides an option to create index entries with a certain length, where “length” refers to the number of characters or bytes in each value which will become part of the index. SQLAlchemy provides this feature via the mysql_length parameter:

Index('my_index', my_table.c.data, mysql_length=10)

Prefix lengths are given in characters for nonbinary string types and in bytes for binary string types. The value passed to the keyword argument will be simply passed through to the underlying CREATE INDEX command, so it must be an integer. MySQL only allows a length for an index if it is for a CHAR, VARCHAR, TEXT, BINARY, VARBINARY and BLOB.

Index Types

Some MySQL storage engines permit you to specify an index type when creating an index or primary key constraint. SQLAlchemy provides this feature via the mysql_using parameter on Index:

Index('my_index', my_table.c.data, mysql_using='hash')

As well as the mysql_using parameter on PrimaryKeyConstraint:

PrimaryKeyConstraint("data", mysql_using='hash')

The value passed to the keyword argument will be simply passed through to the underlying CREATE INDEX or PRIMARY KEY clause, so it must be a valid index type for your MySQL storage engine.

More information can be found at:

http://dev.mysql.com/doc/refman/5.0/en/create-index.html

http://dev.mysql.com/doc/refman/5.0/en/create-table.html

MySQL Data Types

As with all SQLAlchemy dialects, all UPPERCASE types that are known to be valid with MySQL are importable from the top level dialect:

from sqlalchemy.dialects.mysql import \
        BIGINT, BINARY, BIT, BLOB, BOOLEAN, CHAR, DATE, \
        DATETIME, DECIMAL, DECIMAL, DOUBLE, ENUM, FLOAT, INTEGER, \
        LONGBLOB, LONGTEXT, MEDIUMBLOB, MEDIUMINT, MEDIUMTEXT, NCHAR, \
        NUMERIC, NVARCHAR, REAL, SET, SMALLINT, TEXT, TIME, TIMESTAMP, \
        TINYBLOB, TINYINT, TINYTEXT, VARBINARY, VARCHAR, YEAR

Types which are specific to MySQL, or have MySQL-specific construction arguments, are as follows:

class sqlalchemy.dialects.mysql.BIGINT(display_width=None, **kw)

Bases: sqlalchemy.dialects.mysql.base._IntegerType, sqlalchemy.types.BIGINT

MySQL BIGINTEGER type.

__init__(display_width=None, **kw)

Construct a BIGINTEGER.

Parameters:
  • display_width – Optional, maximum display width for this number.
  • unsigned – a boolean, optional.
  • zerofill – Optional. If true, values will be stored as strings left-padded with zeros. Note that this does not effect the values returned by the underlying database API, which continue to be numeric.
class sqlalchemy.dialects.mysql.BINARY(length=None)

Bases: sqlalchemy.types._Binary

The SQL BINARY type.

class sqlalchemy.dialects.mysql.BIT(length=None)

Bases: sqlalchemy.types.TypeEngine

MySQL BIT type.

This type is for MySQL 5.0.3 or greater for MyISAM, and 5.0.5 or greater for MyISAM, MEMORY, InnoDB and BDB. For older versions, use a MSTinyInteger() type.

__init__(length=None)

Construct a BIT.

Parameters:length – Optional, number of bits.
class sqlalchemy.dialects.mysql.BLOB(length=None)

Bases: sqlalchemy.types.LargeBinary

The SQL BLOB type.

__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.mysql.BOOLEAN(create_constraint=True, name=None)

Bases: sqlalchemy.types.Boolean

The SQL BOOLEAN type.

__init__(create_constraint=True, name=None)

Construct a Boolean.

Parameters:
  • create_constraint – defaults to True. 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.
  • name – if a CHECK constraint is generated, specify the name of the constraint.
class sqlalchemy.dialects.mysql.CHAR(length=None, **kwargs)

Bases: sqlalchemy.dialects.mysql.base._StringType, sqlalchemy.types.CHAR

MySQL CHAR type, for fixed-length character data.

__init__(length=None, **kwargs)

Construct a CHAR.

Parameters:
  • length – Maximum data length, in characters.
  • binary – Optional, use the default binary collation for the national character set. This does not affect the type of data stored, use a BINARY type for binary data.
  • collation – Optional, request a particular collation. Must be compatible with the national character set.
class sqlalchemy.dialects.mysql.DATE(*args, **kwargs)

Bases: sqlalchemy.types.Date

The SQL DATE type.

__init__(*args, **kwargs)

Support implementations that were passing arguments

class sqlalchemy.dialects.mysql.DATETIME(timezone=False)

Bases: sqlalchemy.types.DateTime

The SQL DATETIME type.

__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.mysql.DECIMAL(precision=None, scale=None, asdecimal=True, **kw)

Bases: sqlalchemy.dialects.mysql.base._NumericType, sqlalchemy.types.DECIMAL

MySQL DECIMAL type.

__init__(precision=None, scale=None, asdecimal=True, **kw)

Construct a DECIMAL.

Parameters:
  • precision – Total digits in this number. If scale and precision are both None, values are stored to limits allowed by the server.
  • scale – The number of digits after the decimal point.
  • unsigned – a boolean, optional.
  • zerofill – Optional. If true, values will be stored as strings left-padded with zeros. Note that this does not effect the values returned by the underlying database API, which continue to be numeric.
class sqlalchemy.dialects.mysql.DOUBLE(precision=None, scale=None, asdecimal=True, **kw)

Bases: sqlalchemy.dialects.mysql.base._FloatType

MySQL DOUBLE type.

__init__(precision=None, scale=None, asdecimal=True, **kw)

Construct a DOUBLE.

Parameters:
  • precision – Total digits in this number. If scale and precision are both None, values are stored to limits allowed by the server.
  • scale – The number of digits after the decimal point.
  • unsigned – a boolean, optional.
  • zerofill – Optional. If true, values will be stored as strings left-padded with zeros. Note that this does not effect the values returned by the underlying database API, which continue to be numeric.
class sqlalchemy.dialects.mysql.ENUM(*enums, **kw)

Bases: sqlalchemy.types.Enum, sqlalchemy.dialects.mysql.base._StringType

MySQL ENUM type.

__init__(*enums, **kw)

Construct an ENUM.

Example:

Column(‘myenum’, MSEnum(“foo”, “bar”, “baz”))
Parameters:
  • enums – The range of valid values for this ENUM. Values will be quoted when generating the schema according to the quoting flag (see below).
  • strict – Defaults to False: ensure that a given value is in this ENUM’s range of permissible values when inserting or updating rows. Note that MySQL will not raise a fatal error if you attempt to store an out of range value- an alternate value will be stored instead. (See MySQL ENUM documentation.)
  • charset – Optional, a column-level character set for this string value. Takes precedence to ‘ascii’ or ‘unicode’ short-hand.
  • collation – Optional, a column-level collation for this string value. Takes precedence to ‘binary’ short-hand.
  • ascii – Defaults to False: short-hand for the latin1 character set, generates ASCII in schema.
  • unicode – Defaults to False: short-hand for the ucs2 character set, generates UNICODE in schema.
  • binary – Defaults to False: short-hand, pick the binary collation type that matches the column’s character set. Generates BINARY in schema. This does not affect the type of data stored, only the collation of character data.
  • quoting

    Defaults to ‘auto’: automatically determine enum value quoting. If all enum values are surrounded by the same quoting character, then use ‘quoted’ mode. Otherwise, use ‘unquoted’ mode.

    ‘quoted’: values in enums are already quoted, they will be used directly when generating the schema - this usage is deprecated.

    ‘unquoted’: values in enums are not quoted, they will be escaped and surrounded by single quotes when generating the schema.

    Previous versions of this type always required manually quoted values to be supplied; future versions will always quote the string literals for you. This is a transitional option.

class sqlalchemy.dialects.mysql.FLOAT(precision=None, scale=None, asdecimal=False, **kw)

Bases: sqlalchemy.dialects.mysql.base._FloatType, sqlalchemy.types.FLOAT

MySQL FLOAT type.

__init__(precision=None, scale=None, asdecimal=False, **kw)

Construct a FLOAT.

Parameters:
  • precision – Total digits in this number. If scale and precision are both None, values are stored to limits allowed by the server.
  • scale – The number of digits after the decimal point.
  • unsigned – a boolean, optional.
  • zerofill – Optional. If true, values will be stored as strings left-padded with zeros. Note that this does not effect the values returned by the underlying database API, which continue to be numeric.
class sqlalchemy.dialects.mysql.INTEGER(display_width=None, **kw)

Bases: sqlalchemy.dialects.mysql.base._IntegerType, sqlalchemy.types.INTEGER

MySQL INTEGER type.

__init__(display_width=None, **kw)

Construct an INTEGER.

Parameters:
  • display_width – Optional, maximum display width for this number.
  • unsigned – a boolean, optional.
  • zerofill – Optional. If true, values will be stored as strings left-padded with zeros. Note that this does not effect the values returned by the underlying database API, which continue to be numeric.
class sqlalchemy.dialects.mysql.LONGBLOB(length=None)

Bases: sqlalchemy.types._Binary

MySQL LONGBLOB type, for binary data up to 2^32 bytes.

class sqlalchemy.dialects.mysql.LONGTEXT(**kwargs)

Bases: sqlalchemy.dialects.mysql.base._StringType

MySQL LONGTEXT type, for text up to 2^32 characters.

__init__(**kwargs)

Construct a LONGTEXT.

Parameters:
  • charset – Optional, a column-level character set for this string value. Takes precedence to ‘ascii’ or ‘unicode’ short-hand.
  • collation – Optional, a column-level collation for this string value. Takes precedence to ‘binary’ short-hand.
  • ascii – Defaults to False: short-hand for the latin1 character set, generates ASCII in schema.
  • unicode – Defaults to False: short-hand for the ucs2 character set, generates UNICODE in schema.
  • national – Optional. If true, use the server’s configured national character set.
  • binary – Defaults to False: short-hand, pick the binary collation type that matches the column’s character set. Generates BINARY in schema. This does not affect the type of data stored, only the collation of character data.
class sqlalchemy.dialects.mysql.MEDIUMBLOB(length=None)

Bases: sqlalchemy.types._Binary

MySQL MEDIUMBLOB type, for binary data up to 2^24 bytes.

class sqlalchemy.dialects.mysql.MEDIUMINT(display_width=None, **kw)

Bases: sqlalchemy.dialects.mysql.base._IntegerType

MySQL MEDIUMINTEGER type.

__init__(display_width=None, **kw)

Construct a MEDIUMINTEGER

Parameters:
  • display_width – Optional, maximum display width for this number.
  • unsigned – a boolean, optional.
  • zerofill – Optional. If true, values will be stored as strings left-padded with zeros. Note that this does not effect the values returned by the underlying database API, which continue to be numeric.
class sqlalchemy.dialects.mysql.MEDIUMTEXT(**kwargs)

Bases: sqlalchemy.dialects.mysql.base._StringType

MySQL MEDIUMTEXT type, for text up to 2^24 characters.

__init__(**kwargs)

Construct a MEDIUMTEXT.

Parameters:
  • charset – Optional, a column-level character set for this string value. Takes precedence to ‘ascii’ or ‘unicode’ short-hand.
  • collation – Optional, a column-level collation for this string value. Takes precedence to ‘binary’ short-hand.
  • ascii – Defaults to False: short-hand for the latin1 character set, generates ASCII in schema.
  • unicode – Defaults to False: short-hand for the ucs2 character set, generates UNICODE in schema.
  • national – Optional. If true, use the server’s configured national character set.
  • binary – Defaults to False: short-hand, pick the binary collation type that matches the column’s character set. Generates BINARY in schema. This does not affect the type of data stored, only the collation of character data.
class sqlalchemy.dialects.mysql.NCHAR(length=None, **kwargs)

Bases: sqlalchemy.dialects.mysql.base._StringType, sqlalchemy.types.NCHAR

MySQL NCHAR type.

For fixed-length character data in the server’s configured national character set.

__init__(length=None, **kwargs)

Construct an NCHAR.

Parameters:
  • length – Maximum data length, in characters.
  • binary – Optional, use the default binary collation for the national character set. This does not affect the type of data stored, use a BINARY type for binary data.
  • collation – Optional, request a particular collation. Must be compatible with the national character set.
class sqlalchemy.dialects.mysql.NUMERIC(precision=None, scale=None, asdecimal=True, **kw)

Bases: sqlalchemy.dialects.mysql.base._NumericType, sqlalchemy.types.NUMERIC

MySQL NUMERIC type.

__init__(precision=None, scale=None, asdecimal=True, **kw)

Construct a NUMERIC.

Parameters:
  • precision – Total digits in this number. If scale and precision are both None, values are stored to limits allowed by the server.
  • scale – The number of digits after the decimal point.
  • unsigned – a boolean, optional.
  • zerofill – Optional. If true, values will be stored as strings left-padded with zeros. Note that this does not effect the values returned by the underlying database API, which continue to be numeric.
class sqlalchemy.dialects.mysql.NVARCHAR(length=None, **kwargs)

Bases: sqlalchemy.dialects.mysql.base._StringType, sqlalchemy.types.NVARCHAR

MySQL NVARCHAR type.

For variable-length character data in the server’s configured national character set.

__init__(length=None, **kwargs)

Construct an NVARCHAR.

Parameters:
  • length – Maximum data length, in characters.
  • binary – Optional, use the default binary collation for the national character set. This does not affect the type of data stored, use a BINARY type for binary data.
  • collation – Optional, request a particular collation. Must be compatible with the national character set.
class sqlalchemy.dialects.mysql.REAL(precision=None, scale=None, asdecimal=True, **kw)

Bases: sqlalchemy.dialects.mysql.base._FloatType, sqlalchemy.types.REAL

MySQL REAL type.

__init__(precision=None, scale=None, asdecimal=True, **kw)

Construct a REAL.

Parameters:
  • precision – Total digits in this number. If scale and precision are both None, values are stored to limits allowed by the server.
  • scale – The number of digits after the decimal point.
  • unsigned – a boolean, optional.
  • zerofill – Optional. If true, values will be stored as strings left-padded with zeros. Note that this does not effect the values returned by the underlying database API, which continue to be numeric.
class sqlalchemy.dialects.mysql.SET(*values, **kw)

Bases: sqlalchemy.dialects.mysql.base._StringType

MySQL SET type.

__init__(*values, **kw)

Construct a SET.

Example:

Column('myset', MSSet("'foo'", "'bar'", "'baz'"))
Parameters:
  • values – The range of valid values for this SET. Values will be used exactly as they appear when generating schemas. Strings must be quoted, as in the example above. Single-quotes are suggested for ANSI compatibility and are required for portability to servers with ANSI_QUOTES enabled.
  • charset – Optional, a column-level character set for this string value. Takes precedence to ‘ascii’ or ‘unicode’ short-hand.
  • collation – Optional, a column-level collation for this string value. Takes precedence to ‘binary’ short-hand.
  • ascii – Defaults to False: short-hand for the latin1 character set, generates ASCII in schema.
  • unicode – Defaults to False: short-hand for the ucs2 character set, generates UNICODE in schema.
  • binary – Defaults to False: short-hand, pick the binary collation type that matches the column’s character set. Generates BINARY in schema. This does not affect the type of data stored, only the collation of character data.
class sqlalchemy.dialects.mysql.SMALLINT(display_width=None, **kw)

Bases: sqlalchemy.dialects.mysql.base._IntegerType, sqlalchemy.types.SMALLINT

MySQL SMALLINTEGER type.

__init__(display_width=None, **kw)

Construct a SMALLINTEGER.

Parameters:
  • display_width – Optional, maximum display width for this number.
  • unsigned – a boolean, optional.
  • zerofill – Optional. If true, values will be stored as strings left-padded with zeros. Note that this does not effect the values returned by the underlying database API, which continue to be numeric.
class sqlalchemy.dialects.mysql.TEXT(length=None, **kw)

Bases: sqlalchemy.dialects.mysql.base._StringType, sqlalchemy.types.TEXT

MySQL TEXT type, for text up to 2^16 characters.

__init__(length=None, **kw)

Construct a TEXT.

Parameters:
  • length – Optional, if provided the server may optimize storage by substituting the smallest TEXT type sufficient to store length characters.
  • charset – Optional, a column-level character set for this string value. Takes precedence to ‘ascii’ or ‘unicode’ short-hand.
  • collation – Optional, a column-level collation for this string value. Takes precedence to ‘binary’ short-hand.
  • ascii – Defaults to False: short-hand for the latin1 character set, generates ASCII in schema.
  • unicode – Defaults to False: short-hand for the ucs2 character set, generates UNICODE in schema.
  • national – Optional. If true, use the server’s configured national character set.
  • binary – Defaults to False: short-hand, pick the binary collation type that matches the column’s character set. Generates BINARY in schema. This does not affect the type of data stored, only the collation of character data.
class sqlalchemy.dialects.mysql.TIME(timezone=False)

Bases: sqlalchemy.types.Time

The SQL TIME type.

class sqlalchemy.dialects.mysql.TIMESTAMP(timezone=False)

Bases: sqlalchemy.types.TIMESTAMP

MySQL TIMESTAMP type.

__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.mysql.TINYBLOB(length=None)

Bases: sqlalchemy.types._Binary

MySQL TINYBLOB type, for binary data up to 2^8 bytes.

class sqlalchemy.dialects.mysql.TINYINT(display_width=None, **kw)

Bases: sqlalchemy.dialects.mysql.base._IntegerType

MySQL TINYINT type.

__init__(display_width=None, **kw)

Construct a TINYINT.

Note: following the usual MySQL conventions, TINYINT(1) columns reflected during Table(..., autoload=True) are treated as Boolean columns.

Parameters:
  • display_width – Optional, maximum display width for this number.
  • unsigned – a boolean, optional.
  • zerofill – Optional. If true, values will be stored as strings left-padded with zeros. Note that this does not effect the values returned by the underlying database API, which continue to be numeric.
class sqlalchemy.dialects.mysql.TINYTEXT(**kwargs)

Bases: sqlalchemy.dialects.mysql.base._StringType

MySQL TINYTEXT type, for text up to 2^8 characters.

__init__(**kwargs)

Construct a TINYTEXT.

Parameters:
  • charset – Optional, a column-level character set for this string value. Takes precedence to ‘ascii’ or ‘unicode’ short-hand.
  • collation – Optional, a column-level collation for this string value. Takes precedence to ‘binary’ short-hand.
  • ascii – Defaults to False: short-hand for the latin1 character set, generates ASCII in schema.
  • unicode – Defaults to False: short-hand for the ucs2 character set, generates UNICODE in schema.
  • national – Optional. If true, use the server’s configured national character set.
  • binary – Defaults to False: short-hand, pick the binary collation type that matches the column’s character set. Generates BINARY in schema. This does not affect the type of data stored, only the collation of character data.
class sqlalchemy.dialects.mysql.VARBINARY(length=None)

Bases: sqlalchemy.types._Binary

The SQL VARBINARY type.

class sqlalchemy.dialects.mysql.VARCHAR(length=None, **kwargs)

Bases: sqlalchemy.dialects.mysql.base._StringType, sqlalchemy.types.VARCHAR

MySQL VARCHAR type, for variable-length character data.

__init__(length=None, **kwargs)

Construct a VARCHAR.

Parameters:
  • charset – Optional, a column-level character set for this string value. Takes precedence to ‘ascii’ or ‘unicode’ short-hand.
  • collation – Optional, a column-level collation for this string value. Takes precedence to ‘binary’ short-hand.
  • ascii – Defaults to False: short-hand for the latin1 character set, generates ASCII in schema.
  • unicode – Defaults to False: short-hand for the ucs2 character set, generates UNICODE in schema.
  • national – Optional. If true, use the server’s configured national character set.
  • binary – Defaults to False: short-hand, pick the binary collation type that matches the column’s character set. Generates BINARY in schema. This does not affect the type of data stored, only the collation of character data.
class sqlalchemy.dialects.mysql.YEAR(display_width=None)

Bases: sqlalchemy.types.TypeEngine

MySQL YEAR type, for single byte storage of years 1901-2155.

MySQL-Python Notes

Support for the MySQL database via the MySQL-python adapter.

MySQL-Python is available at:

At least version 1.2.1 or 1.2.2 should be used.

Connecting

Connect string format:

mysql+mysqldb://<user>:<password>@<host>[:<port>]/<dbname>

Unicode

MySQLdb will accommodate Python unicode objects if the use_unicode=1 parameter, or the charset parameter, is passed as a connection argument.

Without this setting, many MySQL server installations default to a latin1 encoding for client connections, which has the effect of all data being converted into latin1, even if you have utf8 or another character set configured on your tables and columns. With versions 4.1 and higher, you can change the connection character set either through server configuration or by including the charset parameter. The charset parameter as received by MySQL-Python also has the side-effect of enabling use_unicode=1:

# set client encoding to utf8; all strings come back as unicode
create_engine('mysql+mysqldb:///mydb?charset=utf8')

Manually configuring use_unicode=0 will cause MySQL-python to return encoded strings:

# set client encoding to utf8; all strings come back as utf8 str
create_engine('mysql+mysqldb:///mydb?charset=utf8&use_unicode=0')

Known Issues

MySQL-python version 1.2.2 has a serious memory leak related to unicode conversion, a feature which is disabled via use_unicode=0. It is strongly advised to use the latest version of MySQL-Python.

OurSQL Notes

Support for the MySQL database via the oursql adapter.

OurSQL is available at:

Connecting

Connect string format:

mysql+oursql://<user>:<password>@<host>[:<port>]/<dbname>

Unicode

oursql defaults to using utf8 as the connection charset, but other encodings may be used instead. Like the MySQL-Python driver, unicode support can be completely disabled:

# oursql sets the connection charset to utf8 automatically; all strings come
# back as utf8 str
create_engine('mysql+oursql:///mydb?use_unicode=0')

To not automatically use utf8 and instead use whatever the connection defaults to, there is a separate parameter:

# use the default connection charset; all strings come back as unicode
create_engine('mysql+oursql:///mydb?default_charset=1')

# use latin1 as the connection charset; all strings come back as unicode
create_engine('mysql+oursql:///mydb?charset=latin1')

pymysql Notes

Support for the MySQL database via the pymysql adapter.

pymysql is available at:

Connecting

Connect string:

mysql+pymysql://<username>:<password>@<host>/<dbname>[?<options>]

MySQL-Python Compatibility

The pymysql DBAPI is a pure Python port of the MySQL-python (MySQLdb) driver, and targets 100% compatibility. Most behavioral notes for MySQL-python apply to the pymysql driver as well.

MySQL-Connector Notes

Support for the MySQL database via the MySQL Connector/Python adapter.

MySQL Connector/Python is available at:

Connecting

Connect string format:

mysql+mysqlconnector://<user>:<password>@<host>[:<port>]/<dbname>

Google App Engine Notes

Support for Google Cloud SQL on Google App Engine.

This dialect is based primarily on the mysql.mysqldb dialect with minimal changes.

New in version 0.7.8.

Connecting

Connect string format:

mysql+gaerdbms:///<dbname>

E.g.:

create_engine('mysql+gaerdbms:///mydb',
               connect_args={"instance":"instancename"})

Pooling

Google App Engine connections appear to be randomly recycled, so the dialect does not pool connections. The NullPool implementation is installed within the Engine by default.

pyodbc Notes

Support for the MySQL database via the pyodbc adapter.

pyodbc is available at:

Connecting

Connect string:

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

Limitations

The mysql-pyodbc dialect is subject to unresolved character encoding issues which exist within the current ODBC drivers available. (see http://code.google.com/p/pyodbc/issues/detail?id=25). Consider usage of OurSQL, MySQLdb, or MySQL-connector/Python.

zxjdbc Notes

Support for the MySQL database via Jython’s zxjdbc JDBC connector.

JDBC Driver

The official MySQL JDBC driver is at http://dev.mysql.com/downloads/connector/j/.

Connecting

Connect string format:

mysql+zxjdbc://<user>:<password>@<hostname>[:<port>]/<database>

Character Sets

SQLAlchemy zxjdbc dialects pass unicode straight through to the zxjdbc/JDBC layer. To allow multiple character sets to be sent from the MySQL Connector/J JDBC driver, by default SQLAlchemy sets its characterEncoding connection property to UTF-8. It may be overriden via a create_engine URL parameter.