MySQL¶
Support for the MySQL database.
DBAPI Support¶
The following dialect/DBAPI options are available. Please refer to individual DBAPI sections for connect information.
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.
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)
See also
Setting Pool Recycle - full description of the pool recycle feature.
CREATE TABLE arguments including Storage Engines¶
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.
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 create_engine.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.
AUTO_INCREMENT Behavior¶
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)
)
Unicode¶
Charset Selection¶
Most MySQL DBAPIs offer the option to set the client character set for
a connection. This is typically delivered using the charset
parameter
in the URL, such as:
e = create_engine("mysql+pymysql://scott:tiger@localhost/test?charset=utf8")
This charset is the client character set for the connection. Some
MySQL DBAPIs will default this to a value such as latin1
, and some
will make use of the default-character-set
setting in the my.cnf
file as well. Documentation for the DBAPI in use should be consulted
for specific behavior.
The encoding used for Unicode has traditionally been 'utf8'
. However,
for MySQL versions 5.5.3 on forward, a new MySQL-specific encoding
'utf8mb4'
has been introduced. The rationale for this new encoding
is due to the fact that MySQL’s utf-8 encoding only supports
codepoints up to three bytes instead of four. Therefore,
when communicating with a MySQL database
that includes codepoints more than three bytes in size,
this new charset is preferred, if supported by both the database as well
as the client DBAPI, as in:
e = create_engine("mysql+pymysql://scott:tiger@localhost/test?charset=utf8mb4")
At the moment, up-to-date versions of MySQLdb and PyMySQL support the
utf8mb4
charset. Other DBAPIs such as MySQL-Connector and OurSQL
may not support it as of yet.
In order to use utf8mb4
encoding, changes to
the MySQL schema and/or server configuration may be required.
See also
The utf8mb4 Character Set - in the MySQL documentation
Unicode Encoding / Decoding¶
All modern MySQL DBAPIs all offer the service of handling the encoding and decoding of unicode data between the Python application space and the database. As this was not always the case, SQLAlchemy also includes a comprehensive system of performing the encode/decode task as well. As only one of these systems should be in use at at time, SQLAlchemy has long included functionality to automatically detect upon first connection whether or not the DBAPI is automatically handling unicode.
Whether or not the MySQL DBAPI will handle encoding can usually be configured
using a DBAPI flag use_unicode
, which is known to be supported at least
by MySQLdb, PyMySQL, and MySQL-Connector. Setting this value to 0
in the “connect args” or query string will have the effect of disabling the
DBAPI’s handling of unicode, such that it instead will return data of the
str
type or bytes
type, with data in the configured charset:
# connect while disabling the DBAPI's unicode encoding/decoding
e = create_engine("mysql+mysqldb://scott:tiger@localhost/test?charset=utf8&use_unicode=0")
Current recommendations for modern DBAPIs are as follows:
- It is generally always safe to leave the
use_unicode
flag set at its default; that is, don’t use it at all. - Under Python 3, the
use_unicode=0
flag should never be used. SQLAlchemy under Python 3 generally assumes the DBAPI receives and returns string values as Python 3 strings, which are inherently unicode objects. - Under Python 2 with MySQLdb, the
use_unicode=0
flag will offer superior performance, as MySQLdb’s unicode converters under Python 2 only have been observed to have unusually slow performance compared to SQLAlchemy’s fast C-based encoders/decoders.
In short: don’t specify use_unicode
at all, with the possible
exception of use_unicode=0
on MySQLdb with Python 2 only for a
potential performance gain.
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 add the constants.CLIENT.FOUND_ROWS
flag, or whatever is equivalent for the target dialect, upon connection.
This setting is currently hardcoded.
See also
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)
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.
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:
MySQL Foreign Keys¶
MySQL’s behavior regarding foreign keys has some important caveats.
Foreign Key Arguments to Avoid¶
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
.
Reflection of Foreign Key Constraints¶
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 Unique Constraints and Reflection¶
SQLAlchemy supports both the Index
construct with the
flag unique=True
, indicating a UNIQUE index, as well as the
UniqueConstraint
construct, representing a UNIQUE constraint.
Both objects/syntaxes are supported by MySQL when emitting DDL to create
these constraints. However, MySQL does not have a unique constraint
construct that is separate from a unique index; that is, the “UNIQUE”
constraint on MySQL is equivalent to creating a “UNIQUE INDEX”.
When reflecting these constructs, the Inspector.get_indexes()
and the Inspector.get_unique_constraints()
methods will both
return an entry for a UNIQUE index in MySQL. However, when performing
full table reflection using Table(..., autoload=True)
,
the UniqueConstraint
construct is
not part of the fully reflected Table
construct under any
circumstances; this construct is always represented by a Index
with the unique=True
setting present in the Table.indexes
collection.
TIMESTAMP Columns and NULL¶
MySQL historically 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.
This behavior of MySQL can be changed on the MySQL side using the explicit_defaults_for_timestamp configuration flag introduced in MySQL 5.6. With this server setting enabled, TIMESTAMP columns behave like any other datatype on the MySQL side with regards to defaults and nullability.
However, to accommodate the vast majority of MySQL databases that do not
specify this new flag, SQLAlchemy emits the “NULL” specifier explicitly with
any TIMESTAMP column that does not specify nullable=False
. In order
to accommodate newer databases that specify explicit_defaults_for_timestamp
,
SQLAlchemy also emits NOT NULL for TIMESTAMP columns that do specify
nullable=False
. The following example illustrates:
from sqlalchemy import MetaData, Integer, Table, Column, text
from sqlalchemy.dialects.mysql import TIMESTAMP
m = MetaData()
t = Table('ts_test', m,
Column('a', Integer),
Column('b', Integer, nullable=False),
Column('c', TIMESTAMP),
Column('d', TIMESTAMP, nullable=False)
)
from sqlalchemy import create_engine
e = create_engine("mysql://scott:tiger@localhost/test", echo=True)
m.create_all(e)
output:
CREATE TABLE ts_test (
a INTEGER,
b INTEGER NOT NULL,
c TIMESTAMP NULL,
d TIMESTAMP NOT NULL
)
Changed in version 1.0.0: - SQLAlchemy now renders NULL or NOT NULL in all
cases for TIMESTAMP columns, to accommodate
explicit_defaults_for_timestamp
. Prior to this version, it will
not render “NOT NULL” for a TIMESTAMP column that is nullable=False
.
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:
-
-
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.
-
class
sqlalchemy.dialects.mysql.
BLOB
(length=None)¶ Bases:
sqlalchemy.types.LargeBinary
The SQL BLOB type.
-
__init__
(length=None)¶ - inherited from the
__init__()
method ofLargeBinary
Construct a LargeBinary type.
Parameters: length¶ – optional, a length for the column for use in DDL statements, for those binary types that accept a length, such as the MySQL BLOB type.
-
-
class
sqlalchemy.dialects.mysql.
BOOLEAN
(create_constraint=True, name=None, _create_events=True)¶ Bases:
sqlalchemy.types.Boolean
The SQL BOOLEAN type.
-
__init__
(create_constraint=True, name=None, _create_events=True)¶ - inherited from the
__init__()
method ofBoolean
Construct a Boolean.
Parameters:
-
-
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
¶ Bases:
sqlalchemy.types.Date
The SQL DATE type.
-
__init__
¶ - inherited from the
__init__
attribute ofobject
x.__init__(...) initializes x; see help(type(x)) for signature
-
-
class
sqlalchemy.dialects.mysql.
DATETIME
(timezone=False, fsp=None)¶ Bases:
sqlalchemy.types.DATETIME
MySQL DATETIME type.
-
__init__
(timezone=False, fsp=None)¶ Construct a MySQL DATETIME type.
Parameters: - timezone¶ – not used by the MySQL dialect.
- fsp¶ –
fractional seconds precision value. MySQL 5.6.4 supports storage of fractional seconds; this parameter will be used when emitting DDL for the DATETIME type.
Note
DBAPI driver support for fractional seconds may be limited; current support includes MySQL Connector/Python.
New in version 0.8.5: Added MySQL-specific
mysql.DATETIME
with fractional seconds support.
-
-
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.
Note
The
DOUBLE
type by default converts from float to Decimal, using a truncation that defaults to 10 digits. Specify eitherscale=n
ordecimal_return_scale=n
in order to change this scale, orasdecimal=False
to return values directly as Python floating points.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._EnumeratedValues
MySQL ENUM type.
-
__init__
(*enums, **kw)¶ Construct an ENUM.
E.g.:
Column('myenum', ENUM("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:
-
-
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:
-
-
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.
Note
The
REAL
type by default converts from float to Decimal, using a truncation that defaults to 10 digits. Specify eitherscale=n
ordecimal_return_scale=n
in order to change this scale, orasdecimal=False
to return values directly as Python floating points.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._EnumeratedValues
MySQL SET type.
-
__init__
(*values, **kw)¶ Construct a SET.
E.g.:
Column('myset', SET("foo", "bar", "baz"))
The list of potential values is required in the case that this set will be used to generate DDL for a table, or if the
SET.retrieve_as_bitwise
flag is set to True.Parameters: - values¶ – The range of valid values for this SET.
- convert_unicode¶ – Same flag as that of
String.convert_unicode
. - collation¶ – same as that of
String.collation
- charset¶ – same as that of
VARCHAR.charset
. - ascii¶ – same as that of
VARCHAR.ascii
. - unicode¶ – same as that of
VARCHAR.unicode
. - binary¶ – same as that of
VARCHAR.binary
. - quoting¶ –
Defaults to ‘auto’: automatically determine set value quoting. If all 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.
New in version 0.9.0.
- retrieve_as_bitwise¶ –
if True, the data for the set type will be persisted and selected using an integer value, where a set is coerced into a bitwise mask for persistence. MySQL allows this mode which has the advantage of being able to store values unambiguously, such as the blank string
''
. The datatype will appear as the expressioncol + 0
in a SELECT statement, so that the value is coerced into an integer value in result sets. This flag is required if one wishes to persist a set that can store the blank string''
as a value.Warning
When using
mysql.SET.retrieve_as_bitwise
, it is essential that the list of set values is expressed in the exact same order as exists on the MySQL database.New in version 1.0.0.
-
-
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:
-
-
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.
- length¶ – Optional, if provided the server may optimize storage
by substituting the smallest TEXT type sufficient to store
-
-
class
sqlalchemy.dialects.mysql.
TIME
(timezone=False, fsp=None)¶ Bases:
sqlalchemy.types.TIME
MySQL TIME type.
-
__init__
(timezone=False, fsp=None)¶ Construct a MySQL TIME type.
Parameters: - timezone¶ – not used by the MySQL dialect.
- fsp¶ –
fractional seconds precision value. MySQL 5.6 supports storage of fractional seconds; this parameter will be used when emitting DDL for the TIME type.
Note
DBAPI driver support for fractional seconds may be limited; current support includes MySQL Connector/Python.
New in version 0.8: The MySQL-specific TIME type as well as fractional seconds support.
-
-
class
sqlalchemy.dialects.mysql.
TIMESTAMP
(timezone=False, fsp=None)¶ Bases:
sqlalchemy.types.TIMESTAMP
MySQL TIMESTAMP type.
-
__init__
(timezone=False, fsp=None)¶ Construct a MySQL TIMESTAMP type.
Parameters: - timezone¶ – not used by the MySQL dialect.
- fsp¶ –
fractional seconds precision value. MySQL 5.6.4 supports storage of fractional seconds; this parameter will be used when emitting DDL for the TIMESTAMP type.
Note
DBAPI driver support for fractional seconds may be limited; current support includes MySQL Connector/Python.
New in version 0.8.5: Added MySQL-specific
mysql.TIMESTAMP
with fractional seconds support.
-
-
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.
Parameters:
-
-
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¶
Support for the MySQL database via the MySQL-Python driver.
DBAPI¶
Documentation and download information (if applicable) for MySQL-Python is available at: http://sourceforge.net/projects/mysql-python
Py3K Support¶
Currently, MySQLdb only runs on Python 2 and development has been stopped. mysqlclient is fork of MySQLdb and provides Python 3 support as well as some bugfixes.
Using MySQLdb with Google Cloud SQL¶
Google Cloud SQL now recommends use of the MySQLdb dialect. Connect using a URL like the following:
mysql+mysqldb://root@/<dbname>?unix_socket=/cloudsql/<projectid>:<instancename>
pymysql¶
Support for the MySQL database via the PyMySQL driver.
DBAPI¶
Documentation and download information (if applicable) for PyMySQL is available at: http://www.pymysql.org/
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¶
Support for the MySQL database via the MySQL Connector/Python driver.
DBAPI¶
Documentation and download information (if applicable) for MySQL Connector/Python is available at: http://dev.mysql.com/downloads/connector/python/
cymysql¶
Support for the MySQL database via the CyMySQL driver.
DBAPI¶
Documentation and download information (if applicable) for CyMySQL is available at: https://github.com/nakagami/CyMySQL
OurSQL¶
Support for the MySQL database via the OurSQL driver.
DBAPI¶
Documentation and download information (if applicable) for OurSQL is available at: http://packages.python.org/oursql/
Google App Engine¶
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.
Deprecated since version 1.0: This dialect is no longer necessary for Google Cloud SQL; the MySQLdb dialect can be used directly. Cloud SQL now recommends creating connections via the mysql dialect using the URL format
mysql+mysqldb://root@/<dbname>?unix_socket=/cloudsql/<projectid>:<instancename>
DBAPI¶
Documentation and download information (if applicable) for Google Cloud SQL is available at: https://developers.google.com/appengine/docs/python/cloud-sql/developers-guide
pyodbc¶
Support for the MySQL database via the PyODBC driver.
Note
The PyODBC for MySQL dialect is not well supported, and 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). Other dialects for MySQL are recommended.
DBAPI¶
Documentation and download information (if applicable) for PyODBC is available at: http://pypi.python.org/pypi/pyodbc/
zxjdbc¶
Support for the MySQL database via the zxjdbc for Jython driver.
Note
Jython is not supported by current versions of SQLAlchemy. The zxjdbc dialect should be considered as experimental.
DBAPI¶
Drivers for this database are available at: http://dev.mysql.com/downloads/connector/j/
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
overridden via a create_engine
URL parameter.