Support for the MySQL database.
The following dialect/DBAPI options are available. Please refer to individual DBAPI sections for connect information.
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.
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)
MySQL’s CREATE TABLE syntax includes a wide array of special options, including ENGINE, CHARSET, MAX_ROWS, ROW_FORMAT, INSERT_METHOD, and many more. To accommodate the rendering of these arguments, specify the form mysql_argument_name="value". For example, to specify a table with ENGINE of InnoDB, CHARSET of utf8, and KEY_BLOCK_SIZE of 1024:
Table('mytable', metadata,
Column('data', String(32)),
mysql_engine='InnoDB',
mysql_charset='utf8',
mysql_key_block_size="1024"
)
The MySQL dialect will normally transfer any keyword specified as mysql_keyword_name to be rendered as KEYWORD_NAME in the CREATE TABLE statement. A handful of these names will render with a space instead of an underscore; to support this, the MySQL dialect has awareness of these particular names, which include DATA DIRECTORY (e.g. mysql_data_directory), CHARACTER SET (e.g. mysql_character_set) and INDEX DIRECTORY (e.g. mysql_index_directory).
The most common argument is mysql_engine, which refers to the storage engine for the table. Historically, MySQL server installations would default to MyISAM for this value, although newer versions may be defaulting to InnoDB. The InnoDB engine is typically preferred for its support of transactions and foreign keys.
A Table that is created in a MySQL database with a storage engine of MyISAM will be essentially non-transactional, meaning any INSERT/UPDATE/DELETE statement referring to this table will be invoked as autocommit. It also will have no support for foreign key constraints; while the CREATE TABLE statement accepts foreign key options, when using the MyISAM storage engine these arguments are discarded. Reflecting such a table will also produce no foreign key constraint information.
For fully atomic transactions as well as support for foreign key constraints, all participating CREATE TABLE statements must specify a transactional engine, which in the vast majority of cases is InnoDB.
See also
The InnoDB Storage Engine - on the MySQL website.
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.
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.
When creating tables, SQLAlchemy will automatically set AUTO_INCREMENT on the first Integer primary key column which is not marked as a foreign key:
>>> 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 passing False to the autoincrement argument of 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)
)
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.
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)
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 add the constants.CLIENT.FOUND_ROWS flag, or whatever is equivalent for the target dialect, upon connection. This setting is currently hardcoded.
See also
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 extensions to the Index construct are available.
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)
Index('a_b_idx', my_table.c.a, my_table.c.b, mysql_length={'a': 4,
'b': 9})
Prefix lengths are given in characters for nonbinary string types and in bytes for binary string types. The value passed to the keyword argument must be either an integer (and, thus, specify the same prefix length value for all columns of the index) or a dict in which keys are column names and values are prefix length values for corresponding columns. MySQL only allows a length for a column of an index if it is for a CHAR, VARCHAR, TEXT, BINARY, VARBINARY and BLOB.
New in version 0.8.2: mysql_length may now be specified as a dictionary for use with composite indexes.
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:
MySQL’s behavior regarding foreign keys has some important caveats.
MySQL does not support the foreign key arguments “DEFERRABLE”, “INITIALLY”, or “MATCH”. Using the deferrable or initially keyword argument with ForeignKeyConstraint or ForeignKey will have the effect of these keywords being rendered in a DDL expression, which will then raise an error on MySQL. In order to use these keywords on a foreign key while having them ignored on a MySQL backend, use a custom compile rule:
from sqlalchemy.ext.compiler import compiles
from sqlalchemy.schema import ForeignKeyConstraint
@compiles(ForeignKeyConstraint, "mysql")
def process(element, compiler, **kw):
element.deferrable = element.initially = None
return compiler.visit_foreign_key_constraint(element, **kw)
Changed in version 0.9.0: - the MySQL backend no longer silently ignores the deferrable or initially keyword arguments of ForeignKeyConstraint and ForeignKey.
The “MATCH” keyword is in fact more insidious, and is explicitly disallowed by SQLAlchemy in conjunction with the MySQL backend. This argument is silently ignored by MySQL, but in addition has the effect of ON UPDATE and ON DELETE options also being ignored by the backend. Therefore MATCH should never be used with the MySQL backend; as is the case with DEFERRABLE and INITIALLY, custom compilation rules can be used to correct a MySQL ForeignKeyConstraint at DDL definition time.
New in version 0.9.0: - the MySQL backend will raise a CompileError when the match keyword is used with ForeignKeyConstraint or ForeignKey.
Not all MySQL storage engines support foreign keys. When using the very common MyISAM MySQL storage engine, 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
)
MySQL enforces that a column which specifies the TIMESTAMP datatype implicitly includes a default value of CURRENT_TIMESTAMP, even though this is not stated, and additionally sets the column as NOT NULL, the opposite behavior vs. that of all other datatypes:
mysql> CREATE TABLE ts_test (
-> a INTEGER,
-> b INTEGER NOT NULL,
-> c TIMESTAMP,
-> d TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
-> e TIMESTAMP NULL);
Query OK, 0 rows affected (0.03 sec)
mysql> SHOW CREATE TABLE ts_test;
+---------+-----------------------------------------------------
| Table | Create Table
+---------+-----------------------------------------------------
| ts_test | CREATE TABLE `ts_test` (
`a` int(11) DEFAULT NULL,
`b` int(11) NOT NULL,
`c` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
`d` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
`e` timestamp NULL DEFAULT NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1
Above, we see that an INTEGER column defaults to NULL, unless it is specified with NOT NULL. But when the column is of type TIMESTAMP, an implicit default of CURRENT_TIMESTAMP is generated which also coerces the column to be a NOT NULL, even though we did not specify it as such.
Therefore, the usual “NOT NULL” clause does not apply to a TIMESTAMP column; MySQL selects this implicitly. SQLAlchemy therefore does not render NOT NULL for a TIMESTAMP column on MySQL. However, it does render NULL when we specify nullable=True, or if we leave nullable absent, as it also defaults to True. This is to accommodate the essentially reverse behavior of the NULL flag for TIMESTAMP:
from sqlalchemy import MetaData, TIMESTAMP, Integer, Table, Column, text
m = MetaData()
t = Table('ts_test', m,
Column('a', Integer),
Column('b', Integer, nullable=False),
Column('c', TIMESTAMP),
Column('d', TIMESTAMP, nullable=False),
Column('e', TIMESTAMP, nullable=True)
)
from sqlalchemy import create_engine
e = create_engine("mysql://scott:tiger@localhost/test", echo=True)
m.create_all(e)
In the output, we can see that the TIMESTAMP column receives a different treatment for NULL / NOT NULL vs. that of the INTEGER:
CREATE TABLE ts_test (
a INTEGER,
b INTEGER NOT NULL,
c TIMESTAMP NULL,
d TIMESTAMP,
e TIMESTAMP NULL
)
MySQL above receives the NULL/NOT NULL constraint as is stated in our original Table:
mysql> SHOW CREATE TABLE ts_test;
+---------+---------------------------
| Table | Create Table
+---------+---------------------------
| ts_test | CREATE TABLE `ts_test` (
`a` int(11) DEFAULT NULL,
`b` int(11) NOT NULL,
`c` timestamp NULL DEFAULT NULL,
`d` timestamp NOT NULL DEFAULT '0000-00-00 00:00:00',
`e` timestamp NULL DEFAULT NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1
Be sure to always favor the SHOW CREATE TABLE output over the SQLAlchemy-emitted DDL when checking table definitions, as MySQL’s rules can be hard to predict.
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:
Bases: sqlalchemy.dialects.mysql.base._IntegerType, sqlalchemy.types.BIGINT
MySQL BIGINTEGER type.
Construct a BIGINTEGER.
Parameters: |
---|
Bases: sqlalchemy.types._Binary
The SQL BINARY type.
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.
Bases: sqlalchemy.types.LargeBinary
The SQL BLOB type.
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.Boolean
The SQL BOOLEAN type.
Construct a Boolean.
Parameters: |
---|
Bases: sqlalchemy.dialects.mysql.base._StringType, sqlalchemy.types.CHAR
MySQL CHAR type, for fixed-length character data.
Construct a CHAR.
Parameters: |
|
---|
Bases: sqlalchemy.types.Date
The SQL DATE type.
x.__init__(...) initializes x; see help(type(x)) for signature
Bases: sqlalchemy.types.DATETIME
MySQL DATETIME type.
Construct a MySQL DATETIME type.
Parameters: |
|
---|
New in version 0.8.5: Added MySQL-specific mysql.DATETIME with fractional seconds support.
Bases: sqlalchemy.dialects.mysql.base._NumericType, sqlalchemy.types.DECIMAL
MySQL DECIMAL type.
Construct a DECIMAL.
Parameters: |
|
---|
Bases: sqlalchemy.dialects.mysql.base._FloatType
MySQL DOUBLE type.
Construct a DOUBLE.
Note
The DOUBLE type by default converts from float to Decimal, using a truncation that defaults to 10 digits. Specify either scale=n or decimal_return_scale=n in order to change this scale, or asdecimal=False to return values directly as Python floating points.
Parameters: |
|
---|
Bases: sqlalchemy.types.Enum, sqlalchemy.dialects.mysql.base._EnumeratedValues
MySQL ENUM type.
Construct an ENUM.
E.g.:
Column('myenum', ENUM("foo", "bar", "baz"))
Parameters: |
|
---|
Bases: sqlalchemy.dialects.mysql.base._FloatType, sqlalchemy.types.FLOAT
MySQL FLOAT type.
Construct a FLOAT.
Parameters: |
|
---|
Bases: sqlalchemy.dialects.mysql.base._IntegerType, sqlalchemy.types.INTEGER
MySQL INTEGER type.
Construct an INTEGER.
Parameters: |
---|
Bases: sqlalchemy.types._Binary
MySQL LONGBLOB type, for binary data up to 2^32 bytes.
Bases: sqlalchemy.dialects.mysql.base._StringType
MySQL LONGTEXT type, for text up to 2^32 characters.
Construct a LONGTEXT.
Parameters: |
|
---|
Bases: sqlalchemy.types._Binary
MySQL MEDIUMBLOB type, for binary data up to 2^24 bytes.
Bases: sqlalchemy.dialects.mysql.base._IntegerType
MySQL MEDIUMINTEGER type.
Construct a MEDIUMINTEGER
Parameters: |
---|
Bases: sqlalchemy.dialects.mysql.base._StringType
MySQL MEDIUMTEXT type, for text up to 2^24 characters.
Construct a MEDIUMTEXT.
Parameters: |
|
---|
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.
Construct an NCHAR.
Parameters: |
|
---|
Bases: sqlalchemy.dialects.mysql.base._NumericType, sqlalchemy.types.NUMERIC
MySQL NUMERIC type.
Construct a NUMERIC.
Parameters: |
|
---|
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.
Construct an NVARCHAR.
Parameters: |
|
---|
Bases: sqlalchemy.dialects.mysql.base._FloatType, sqlalchemy.types.REAL
MySQL REAL type.
Construct a REAL.
Note
The REAL type by default converts from float to Decimal, using a truncation that defaults to 10 digits. Specify either scale=n or decimal_return_scale=n in order to change this scale, or asdecimal=False to return values directly as Python floating points.
Parameters: |
|
---|
Bases: sqlalchemy.dialects.mysql.base._EnumeratedValues
MySQL SET type.
Construct a SET.
E.g.:
Column('myset', SET("foo", "bar", "baz"))
Parameters: |
|
---|
Bases: sqlalchemy.dialects.mysql.base._IntegerType, sqlalchemy.types.SMALLINT
MySQL SMALLINTEGER type.
Construct a SMALLINTEGER.
Parameters: |
---|
Bases: sqlalchemy.dialects.mysql.base._StringType, sqlalchemy.types.TEXT
MySQL TEXT type, for text up to 2^16 characters.
Construct a TEXT.
Parameters: |
|
---|
Bases: sqlalchemy.types.TIME
MySQL TIME type.
Construct a MySQL TIME type.
Parameters: |
|
---|
New in version 0.8: The MySQL-specific TIME type as well as fractional seconds support.
Bases: sqlalchemy.types.TIMESTAMP
MySQL TIMESTAMP type.
Construct a MySQL TIMESTAMP type.
Parameters: |
|
---|
New in version 0.8.5: Added MySQL-specific mysql.TIMESTAMP with fractional seconds support.
Bases: sqlalchemy.types._Binary
MySQL TINYBLOB type, for binary data up to 2^8 bytes.
Bases: sqlalchemy.dialects.mysql.base._IntegerType
MySQL TINYINT type.
Construct a TINYINT.
Parameters: |
---|
Bases: sqlalchemy.dialects.mysql.base._StringType
MySQL TINYTEXT type, for text up to 2^8 characters.
Construct a TINYTEXT.
Parameters: |
|
---|
Bases: sqlalchemy.types._Binary
The SQL VARBINARY type.
Bases: sqlalchemy.dialects.mysql.base._StringType, sqlalchemy.types.VARCHAR
MySQL VARCHAR type, for variable-length character data.
Construct a VARCHAR.
Parameters: |
|
---|
Bases: sqlalchemy.types.TypeEngine
MySQL YEAR type, for single byte storage of years 1901-2155.
Support for the MySQL database via the MySQL-Python driver.
Documentation and download information (if applicable) for MySQL-Python is available at: http://sourceforge.net/projects/mysql-python
MySQLdb requires a “charset” parameter to be passed in order for it to handle non-ASCII characters correctly. When this parameter is passed, MySQLdb will also implicitly set the “use_unicode” flag to true, which means that it will return Python unicode objects instead of bytestrings. However, SQLAlchemy’s decode process, when C extensions are enabled, is orders of magnitude faster than that of MySQLdb as it does not call into Python functions to do so. Therefore, the recommended URL to use for unicode will include both charset and use_unicode=0:
create_engine("mysql+mysqldb://user:pass@host/dbname?charset=utf8&use_unicode=0")
As of this writing, MySQLdb only runs on Python 2. It is not known how MySQLdb behaves on Python 3 as far as unicode decoding.
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.
Support for the MySQL database via the OurSQL driver.
Documentation and download information (if applicable) for OurSQL is available at: http://packages.python.org/oursql/
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')
Support for the MySQL database via the PyMySQL driver.
Documentation and download information (if applicable) for PyMySQL is available at: http://code.google.com/p/pymysql/
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.
Support for the MySQL database via the MySQL Connector/Python driver.
Documentation and download information (if applicable) for MySQL Connector/Python is available at: http://dev.mysql.com/downloads/connector/python/
Support for the MySQL database via the CyMySQL driver.
Documentation and download information (if applicable) for CyMySQL is available at: https://github.com/nakagami/CyMySQL
Support for the MySQL database via the Google Cloud SQL driver.
This dialect is based primarily on the mysql.mysqldb dialect with minimal changes.
New in version 0.7.8.
Documentation and download information (if applicable) for Google Cloud SQL is available at: https://developers.google.com/appengine/docs/python/cloud-sql/developers-guide
Support for the MySQL database via the PyODBC driver.
Documentation and download information (if applicable) for PyODBC is available at: http://pypi.python.org/pypi/pyodbc/
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.
Support for the MySQL database via the zxjdbc for Jython driver.
Drivers for this database are available at: http://dev.mysql.com/downloads/connector/j/
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 overridden via a create_engine URL parameter.