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 a fixed period of time, defaulting to eight hours.
To circumvent having this issue, use
the create_engine.pool_recycle
option which ensures that
a connection will be discarded and replaced with a new one if it has been
present in the pool for a fixed number of seconds:
engine = create_engine('mysql+mysqldb://...', pool_recycle=3600)
For more comprehensive disconnect detection of pooled connections, including accommodation of server restarts and network issues, a pre-ping approach may be employed. See Dealing with Disconnects for current approaches.
See also
Dealing with Disconnects - Background on several techniques for dealing with timed out connections as well as database restarts.
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 utf8mb4
, and KEY_BLOCK_SIZE
of 1024
:
Table('mytable', metadata,
Column('data', String(32)),
mysql_engine='InnoDB',
mysql_charset='utf8mb4',
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.
All MySQL dialects support setting of transaction isolation level both via a
dialect-specific parameter create_engine.isolation_level
accepted
by create_engine()
, as well as the
Connection.execution_options.isolation_level
argument as passed to
Connection.execution_options()
. This feature works by issuing the
command SET SESSION TRANSACTION ISOLATION LEVEL <level>
for each new
connection. For the special AUTOCOMMIT isolation level, DBAPI-specific
techniques are used.
To set isolation level using create_engine()
:
engine = create_engine(
"mysql://scott:tiger@localhost/test",
isolation_level="READ UNCOMMITTED"
)
To set using per-connection execution options:
connection = engine.connect()
connection = connection.execution_options(
isolation_level="READ COMMITTED"
)
Valid values for isolation_level
include:
READ COMMITTED
READ UNCOMMITTED
REPEATABLE READ
SERIALIZABLE
AUTOCOMMIT
The special AUTOCOMMIT
value makes use of the various “autocommit”
attributes provided by specific DBAPIs, and is currently supported by
MySQLdb, MySQL-Client, MySQL-Connector Python, and PyMySQL. Using it,
the MySQL connection will return true for the value of
SELECT @@autocommit;
.
New in version 1.1: - added support for the AUTOCOMMIT isolation level.
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)
)
Server-side cursor support is available for the MySQLdb and PyMySQL dialects.
From a MySQL point of view this means that the MySQLdb.cursors.SSCursor
or
pymysql.cursors.SSCursor
class is used when building up the cursor which
will receive results. The most typical way of invoking this feature is via the
Connection.execution_options.stream_results
connection execution
option. Server side cursors can also be enabled for all SELECT statements
unconditionally by passing server_side_cursors=True
to
create_engine()
.
New in version 1.1.4: - added server-side cursor support.
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=utf8mb4")
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, and as of MySQL 8.0 a warning is emitted
by the server if plain utf8
is specified within any server-side
directives, replaced with utf8mb3
. The rationale for this new encoding
is due to the fact that MySQL’s legacy 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")
All modern DBAPIs should support the utf8mb4
charset.
In order to use utf8mb4
encoding for a schema that was created with legacy
utf8
, changes to the MySQL schema and/or server configuration may be
required.
See also
The utf8mb4 Character Set - in the MySQL documentation
MySQL versions 5.6, 5.7 and later (not MariaDB at the time of this writing) now emit a warning when attempting to pass binary data to the database, while a character set encoding is also in place, when the binary data itself is not valid for that encoding:
default.py:509: Warning: (1300, "Invalid utf8mb4 character string:
'F9876A'")
cursor.execute(statement, parameters)
This warning is due to the fact that the MySQL client library is attempting to
interpret the binary string as a unicode object even if a datatype such
as LargeBinary
is in use. To resolve this, the SQL statement requires
a binary “character set introducer” be present before any non-NULL value
that renders like this:
INSERT INTO table (data) VALUES (_binary %s)
These character set introducers are provided by the DBAPI driver, assuming the
use of mysqlclient or PyMySQL (both of which are recommended). Add the query
string parameter binary_prefix=true
to the URL to repair this warning:
# mysqlclient
engine = create_engine(
"mysql+mysqldb://scott:tiger@localhost/test?charset=utf8mb4&binary_prefix=true")
# PyMySQL
engine = create_engine(
"mysql+pymysql://scott:tiger@localhost/test?charset=utf8mb4&binary_prefix=true")
The binary_prefix
flag may or may not be supported by other MySQL drivers.
SQLAlchemy itself cannot render this _binary
prefix reliably, as it does
not work with the NULL value, which is valid to be sent as a bound parameter.
As the MySQL driver renders parameters directly into the SQL string, it’s the
most efficient place for this additional keyword to be passed.
See also
Character set introducers - on the MySQL website
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.
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.
INSERT..ON DUPLICATE KEY UPDATE: See INSERT…ON DUPLICATE KEY UPDATE (Upsert)
SELECT pragma, use Select.prefix_with()
and Query.prefix_with()
:
select(...).prefix_with(['HIGH_PRIORITY', 'SQL_SMALL_RESULT'])
UPDATE with LIMIT:
update(..., mysql_limit=10)
optimizer hints, use Select.prefix_with()
and Query.prefix_with()
:
select(...).prefix_with("/*+ NO_RANGE_OPTIMIZATION(t4 PRIMARY) */")
index hints, use Select.with_hint()
and Query.with_hint()
:
select(...).with_hint(some_table, "USE INDEX xyz")
MySQL allows “upserts” (update or insert)
of rows into a table via the ON DUPLICATE KEY UPDATE
clause of the
INSERT
statement. A candidate row will only be inserted if that row does
not match an existing primary or unique key in the table; otherwise, an UPDATE
will be performed. The statement allows for separate specification of the
values to INSERT versus the values for UPDATE.
SQLAlchemy provides ON DUPLICATE KEY UPDATE
support via the MySQL-specific
mysql.dml.insert()
function, which provides
the generative method on_duplicate_key_update()
:
from sqlalchemy.dialects.mysql import insert
insert_stmt = insert(my_table).values(
id='some_existing_id',
data='inserted value')
on_duplicate_key_stmt = insert_stmt.on_duplicate_key_update(
data=insert_stmt.inserted.data,
status='U'
)
conn.execute(on_duplicate_key_stmt)
Unlike PostgreSQL’s “ON CONFLICT” phrase, the “ON DUPLICATE KEY UPDATE” phrase will always match on any primary key or unique key, and will always perform an UPDATE if there’s a match; there are no options for it to raise an error or to skip performing an UPDATE.
ON DUPLICATE KEY UPDATE
is used to perform an update of the already
existing row, using any combination of new values as well as values
from the proposed insertion. These values are normally specified using
keyword arguments passed to the
on_duplicate_key_update()
given column key values (usually the name of the column, unless it
specifies Column.key
) as keys and literal or SQL expressions
as values:
on_duplicate_key_stmt = insert_stmt.on_duplicate_key_update(
data="some data",
updated_at=func.current_timestamp(),
)
In a manner similar to that of UpdateBase.values()
, other parameter
forms are accepted, including a single dictionary:
on_duplicate_key_stmt = insert_stmt.on_duplicate_key_update(
{"data": "some data", "updated_at": func.current_timestamp()},
)
as well as a list of 2-tuples, which will automatically provide
a parameter-ordered UPDATE statement in a manner similar to that described
at Parameter-Ordered Updates. Unlike the Update
object,
no special flag is needed to specify the intent since the argument form is
this context is unambiguous:
on_duplicate_key_stmt = insert_stmt.on_duplicate_key_update(
[
("data", "some data"),
("updated_at", func.current_timestamp()),
],
)
Changed in version 1.3: support for parameter-ordered UPDATE clause within MySQL ON DUPLICATE KEY UPDATE
Warning
The Insert.on_duplicate_key_update()
method does not take into
account Python-side default UPDATE values or generation functions, e.g.
e.g. those specified using Column.onupdate
.
These values will not be exercised for an ON DUPLICATE KEY style of UPDATE,
unless they are manually specified explicitly in the parameters.
In order to refer to the proposed insertion row, the special alias
inserted
is available as an attribute on
the mysql.dml.Insert
object; this object is a
ColumnCollection
which contains all columns of the target
table:
from sqlalchemy.dialects.mysql import insert
stmt = insert(my_table).values(
id='some_id',
data='inserted value',
author='jlh')
do_update_stmt = stmt.on_duplicate_key_update(
data="updated value",
author=stmt.inserted.author
)
conn.execute(do_update_stmt)
When rendered, the “inserted” namespace will produce the expression
VALUES(<columnname>)
.
New in version 1.2: Added support for MySQL ON DUPLICATE KEY UPDATE clause
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.
MySQL storage engines permit you to specify an index prefix when creating
an index. SQLAlchemy provides this feature via the
mysql_prefix
parameter on Index
:
Index('my_index', my_table.c.data, mysql_prefix='FULLTEXT')
The value passed to the keyword argument will be simply passed through to the underlying CREATE INDEX, so it must be a valid index prefix for your MySQL storage engine.
New in version 1.1.5.
See also
CREATE INDEX - MySQL documentation
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:
CREATE FULLTEXT INDEX in MySQL also supports a “WITH PARSER” option. This
is available using the keyword argument mysql_with_parser
:
Index(
'my_index', my_table.c.data,
mysql_prefix='FULLTEXT', mysql_with_parser="ngram")
New in version 1.3.
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
)
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.
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
.
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:
sqlalchemy.dialects.mysql.
BIGINT
(display_width=None, **kw)¶Bases: sqlalchemy.dialects.mysql.types._IntegerType
, sqlalchemy.types.BIGINT
MySQL BIGINTEGER type.
__init__
(display_width=None, **kw)¶Construct a BIGINTEGER.
Parameters: |
---|
sqlalchemy.dialects.mysql.
BINARY
(length=None)¶Bases: sqlalchemy.types._Binary
The SQL BINARY type.
__init__
(length=None)¶__init__()
method of _Binary
Initialize self. See help(type(self)) for accurate signature.
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.
sqlalchemy.dialects.mysql.
BLOB
(length=None)¶Bases: sqlalchemy.types.LargeBinary
The SQL BLOB type.
__init__
(length=None)¶__init__()
method of LargeBinary
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. |
---|
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)¶__init__()
method of Boolean
Construct a Boolean.
Parameters: |
---|
sqlalchemy.dialects.mysql.
CHAR
(length=None, **kwargs)¶Bases: sqlalchemy.dialects.mysql.types._StringType
, sqlalchemy.types.CHAR
MySQL CHAR type, for fixed-length character data.
__init__
(length=None, **kwargs)¶Construct a CHAR.
Parameters: |
|
---|
sqlalchemy.dialects.mysql.
DATE
¶Bases: sqlalchemy.types.Date
The SQL DATE type.
__init__
¶__init__
attribute of object
Initialize self. See help(type(self)) for accurate signature.
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: |
|
---|
sqlalchemy.dialects.mysql.
DECIMAL
(precision=None, scale=None, asdecimal=True, **kw)¶Bases: sqlalchemy.dialects.mysql.types._NumericType
, sqlalchemy.types.DECIMAL
MySQL DECIMAL type.
__init__
(precision=None, scale=None, asdecimal=True, **kw)¶Construct a DECIMAL.
Parameters: |
|
---|
sqlalchemy.dialects.mysql.
DOUBLE
(precision=None, scale=None, asdecimal=True, **kw)¶Bases: sqlalchemy.dialects.mysql.types._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 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: |
|
---|
sqlalchemy.dialects.mysql.
ENUM
(*enums, **kw)¶Bases: sqlalchemy.types.NativeForEmulated
, sqlalchemy.types.Enum
, sqlalchemy.dialects.mysql.enumerated._EnumeratedValues
MySQL ENUM type.
__init__
(*enums, **kw)¶Construct an ENUM.
E.g.:
Column('myenum', ENUM("foo", "bar", "baz"))
Parameters: |
|
---|
sqlalchemy.dialects.mysql.
FLOAT
(precision=None, scale=None, asdecimal=False, **kw)¶Bases: sqlalchemy.dialects.mysql.types._FloatType
, sqlalchemy.types.FLOAT
MySQL FLOAT type.
__init__
(precision=None, scale=None, asdecimal=False, **kw)¶Construct a FLOAT.
Parameters: |
|
---|
sqlalchemy.dialects.mysql.
INTEGER
(display_width=None, **kw)¶Bases: sqlalchemy.dialects.mysql.types._IntegerType
, sqlalchemy.types.INTEGER
MySQL INTEGER type.
__init__
(display_width=None, **kw)¶Construct an INTEGER.
Parameters: |
---|
sqlalchemy.dialects.mysql.
JSON
(none_as_null=False)¶Bases: sqlalchemy.types.JSON
MySQL JSON type.
MySQL supports JSON as of version 5.7. Note that MariaDB does not support JSON at the time of this writing.
The mysql.JSON
type supports persistence of JSON values
as well as the core index operations provided by types.JSON
datatype, by adapting the operations to render the JSON_EXTRACT
function at the database level.
New in version 1.1.
sqlalchemy.dialects.mysql.
LONGBLOB
(length=None)¶Bases: sqlalchemy.types._Binary
MySQL LONGBLOB type, for binary data up to 2^32 bytes.
__init__
(length=None)¶__init__()
method of _Binary
Initialize self. See help(type(self)) for accurate signature.
sqlalchemy.dialects.mysql.
LONGTEXT
(**kwargs)¶Bases: sqlalchemy.dialects.mysql.types._StringType
MySQL LONGTEXT type, for text up to 2^32 characters.
__init__
(**kwargs)¶Construct a LONGTEXT.
Parameters: |
|
---|
sqlalchemy.dialects.mysql.
MEDIUMBLOB
(length=None)¶Bases: sqlalchemy.types._Binary
MySQL MEDIUMBLOB type, for binary data up to 2^24 bytes.
__init__
(length=None)¶__init__()
method of _Binary
Initialize self. See help(type(self)) for accurate signature.
sqlalchemy.dialects.mysql.
MEDIUMINT
(display_width=None, **kw)¶Bases: sqlalchemy.dialects.mysql.types._IntegerType
MySQL MEDIUMINTEGER type.
__init__
(display_width=None, **kw)¶Construct a MEDIUMINTEGER
Parameters: |
---|
sqlalchemy.dialects.mysql.
MEDIUMTEXT
(**kwargs)¶Bases: sqlalchemy.dialects.mysql.types._StringType
MySQL MEDIUMTEXT type, for text up to 2^24 characters.
__init__
(**kwargs)¶Construct a MEDIUMTEXT.
Parameters: |
|
---|
sqlalchemy.dialects.mysql.
NCHAR
(length=None, **kwargs)¶Bases: sqlalchemy.dialects.mysql.types._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: |
|
---|
sqlalchemy.dialects.mysql.
NUMERIC
(precision=None, scale=None, asdecimal=True, **kw)¶Bases: sqlalchemy.dialects.mysql.types._NumericType
, sqlalchemy.types.NUMERIC
MySQL NUMERIC type.
__init__
(precision=None, scale=None, asdecimal=True, **kw)¶Construct a NUMERIC.
Parameters: |
|
---|
sqlalchemy.dialects.mysql.
NVARCHAR
(length=None, **kwargs)¶Bases: sqlalchemy.dialects.mysql.types._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: |
|
---|
sqlalchemy.dialects.mysql.
REAL
(precision=None, scale=None, asdecimal=True, **kw)¶Bases: sqlalchemy.dialects.mysql.types._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 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: |
|
---|
sqlalchemy.dialects.mysql.
SET
(*values, **kw)¶Bases: sqlalchemy.dialects.mysql.enumerated._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: |
|
---|
sqlalchemy.dialects.mysql.
SMALLINT
(display_width=None, **kw)¶Bases: sqlalchemy.dialects.mysql.types._IntegerType
, sqlalchemy.types.SMALLINT
MySQL SMALLINTEGER type.
__init__
(display_width=None, **kw)¶Construct a SMALLINTEGER.
Parameters: |
---|
sqlalchemy.dialects.mysql.
TEXT
(length=None, **kw)¶Bases: sqlalchemy.dialects.mysql.types._StringType
, sqlalchemy.types.TEXT
MySQL TEXT type, for text up to 2^16 characters.
__init__
(length=None, **kw)¶Construct a TEXT.
Parameters: |
|
---|
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: |
|
---|
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: |
|
---|
sqlalchemy.dialects.mysql.
TINYBLOB
(length=None)¶Bases: sqlalchemy.types._Binary
MySQL TINYBLOB type, for binary data up to 2^8 bytes.
__init__
(length=None)¶__init__()
method of _Binary
Initialize self. See help(type(self)) for accurate signature.
sqlalchemy.dialects.mysql.
TINYINT
(display_width=None, **kw)¶Bases: sqlalchemy.dialects.mysql.types._IntegerType
MySQL TINYINT type.
__init__
(display_width=None, **kw)¶Construct a TINYINT.
Parameters: |
---|
sqlalchemy.dialects.mysql.
TINYTEXT
(**kwargs)¶Bases: sqlalchemy.dialects.mysql.types._StringType
MySQL TINYTEXT type, for text up to 2^8 characters.
__init__
(**kwargs)¶Construct a TINYTEXT.
Parameters: |
|
---|
sqlalchemy.dialects.mysql.
VARBINARY
(length=None)¶Bases: sqlalchemy.types._Binary
The SQL VARBINARY type.
__init__
(length=None)¶__init__()
method of _Binary
Initialize self. See help(type(self)) for accurate signature.
sqlalchemy.dialects.mysql.
VARCHAR
(length=None, **kwargs)¶Bases: sqlalchemy.dialects.mysql.types._StringType
, sqlalchemy.types.VARCHAR
MySQL VARCHAR type, for variable-length character data.
__init__
(length=None, **kwargs)¶Construct a VARCHAR.
Parameters: |
|
---|
sqlalchemy.dialects.mysql.
YEAR
(display_width=None)¶Bases: sqlalchemy.types.TypeEngine
MySQL YEAR type, for single byte storage of years 1901-2155.
__init__
(display_width=None)¶Initialize self. See help(type(self)) for accurate signature.
sqlalchemy.dialects.mysql.dml.
insert
(table, values=None, inline=False, bind=None, prefixes=None, returning=None, return_defaults=False, **dialect_kw)¶Construct a new Insert
object.
This constructor is mirrored as a public API function; see insert()
for a full usage and argument description.
sqlalchemy.dialects.mysql.dml.
Insert
(table, values=None, inline=False, bind=None, prefixes=None, returning=None, return_defaults=False, **dialect_kw)¶Bases: sqlalchemy.sql.expression.Insert
MySQL-specific implementation of INSERT.
Adds methods for MySQL-specific syntaxes such as ON DUPLICATE KEY UPDATE.
New in version 1.2.
inserted
¶Provide the “inserted” namespace for an ON DUPLICATE KEY UPDATE statement
MySQL’s ON DUPLICATE KEY UPDATE clause allows reference to the row
that would be inserted, via a special function called VALUES()
.
This attribute provides all columns in this row to be referenceable
such that they will render within a VALUES()
function inside the
ON DUPLICATE KEY UPDATE clause. The attribute is named .inserted
so as not to conflict with the existing Insert.values()
method.
See also
INSERT…ON DUPLICATE KEY UPDATE (Upsert) - example of how
to use Insert.inserted
on_duplicate_key_update
(*args, **kw)¶Specifies the ON DUPLICATE KEY UPDATE clause.
Parameters: | **kw¶ – Column keys linked to UPDATE values. The values may be any SQL expression or supported literal Python values. |
---|
Warning
This dictionary does not take into account
Python-specified default UPDATE values or generation functions,
e.g. those specified using Column.onupdate
.
These values will not be exercised for an ON DUPLICATE KEY UPDATE
style of UPDATE, unless values are manually specified here.
Parameters: | *args¶ – As an alternative to passing key/value parameters, a dictionary or list of 2-tuples can be passed as a single positional argument. Passing a single dictionary is equivalent to the keyword argument form: insert().on_duplicate_key_update({"name": "some name"}) Passing a list of 2-tuples indicates that the parameter assignments
in the UPDATE clause should be ordered as sent, in a manner similar
to that described for the insert().on_duplicate_key_update(
[("name", "some name"), ("value", "some value")]) Changed in version 1.3: parameters can be specified as a dictionary or list of 2-tuples; the latter form provides for parameter ordering. |
---|
New in version 1.2.
Support for the MySQL database via the mysqlclient (maintained fork of MySQL-Python) driver.
Documentation and download information (if applicable) for mysqlclient (maintained fork of MySQL-Python) is available at: https://pypi.org/project/mysqlclient/
The mysqlclient DBAPI is a maintained fork of the MySQL-Python DBAPI that is no longer maintained. mysqlclient supports Python 2 and Python 3 and is very stable.
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>
The mysqldb dialect supports server-side cursors. See Server Side Cursors.
Support for the MySQL database via the PyMySQL driver.
Documentation and download information (if applicable) for PyMySQL is available at: https://pymysql.readthedocs.io/
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: https://pypi.org/project/mysql-connector-python/
Note
The MySQL Connector/Python DBAPI has had many issues since its release, some of which may remain unresolved, and the mysqlconnector dialect is not tested as part of SQLAlchemy’s continuous integration. The recommended MySQL dialects are mysqlclient and PyMySQL.
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
Note
The CyMySQL dialect is not tested as part of SQLAlchemy’s continuous integration and may have unresolved issues. The recommended MySQL dialects are mysqlclient and PyMySQL.
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/
Note
The OurSQL MySQL dialect is legacy and is no longer supported upstream, and is not tested as part of SQLAlchemy’s continuous integration. The recommended MySQL dialects are mysqlclient and PyMySQL.
Support for the MySQL database via the Google Cloud SQL driver.
This dialect is based primarily on the mysql.mysqldb
dialect with
minimal changes.
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>
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.
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.
Documentation and download information (if applicable) for PyODBC is available at: http://pypi.python.org/pypi/pyodbc/
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.
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.