MySQLdb is a thin Python wrapper around _mysql
which makes it compatible with the Python DB API interface (version
2). In reality, a fair amount of the code which implements the API is
in _mysql for the sake of efficiency.
The
DB API specification should be your primary guide for using
this module. Only deviations from the spec and other
database-dependent things will be documented here.
Only a few top-level functions and attributes are defined within
MySQLdb.
connect(parameters...)
Constructor
for creating a connection to the database. Returns a Connection
Object. Parameters are the same as for the MySQL C API. In
addition, there are a few additional keywords that correspond to
what you would pass mysql_options() before connecting. Note
that some parameters must be specified as keyword arguments! The
default value for each parameter is NULL or zero, as
appropriate. Consult the MySQL documentation for more
details. The important parameters are:
host
name of host to connect to. Default: use the local host
via a UNIX socket (where applicable)
user
user to authenticate as. Default: current effective user.
passwd
password to authenticate with. Default: no password.
db
database to use. Default: no default database.
port
TCP port of MySQL server. Default: standard port (3306).
unix_socket
location of UNIX socket. Default: use default location or
TCP for remote hosts.
conv
type conversion dictionary.
Default: a copy of MySQLdb.converters.conversions
compress
Enable protocol compression. Default: no compression.
connect_timeout
Abort if connect is not completed within
given number of seconds. Default: no timeout (?)
named_pipe
Use a named pipe (Windows). Default: don't.
init_command
Initial command to issue to server upon
connection. Default: Nothing.
read_default_file
MySQL configuration file to read; see
the MySQL documentation for mysql_options().
read_default_group
Default group to read; see the MySQL
documentation for mysql_options().
cursorclass
cursor class that cursor() uses,
unless overridden. Default: MySQLdb.cursors.Cursor.
This must be a keyword parameter.
unicode
If set, CHAR and VARCHAR columns are returned
as Unicode strings, using the specified character set.
None means to use a default encoding.
apilevel
String constant stating the supported DB API level. '2.0'
threadsafety
Integer constant stating the level of thread
safety the interface supports. As of MySQLdb version 0.9.0, this
is set to 1, which means: Threads may share the module.
The MySQL protocol can not handle multiple threads using the
same connection at once. Some earlier versions of MySQLdb utilized locking
to achieve a threadsafety of 2. While this is not terribly hard
to accomplish using the standard Cursor class (which uses
mysql_store_result()), it is complicated by SSCursor (which
uses mysql_use_result(); with the latter you must ensure
all the rows have been read before another query can be executed.
It is further complicated by the addition of transactions, since
transactions start when a cursor execute a query, but end when
COMMIT or ROLLBACK is executed by the Connection object.
Two threads cannot share a connection while a transaction is in
progress, in addition to not being able to share it during query
execution. This excessively complicated the code to the point where
it just isn't worth it.
The general upshot of this is: Don't
share connections between threads. It's really not worth your effort
or mine, and in the end, will probably hurt performance, since the MySQL
server runs a separate thread for each connection.
You can certainly do things like
cache connections in a pool, and give those connections to one
thread at a time. If you let two threads use a connection simultaneously,
the MySQL client library will probably upchuck and die.
You have been warned.
For threaded applications, try using a connection pool.
This can be done using the
Pool module.
paramstyle
String constant stating the type of parameter
marker formatting expected by the interface. Set to 'format' =
ANSI C printf format codes, e.g. '...WHERE name=%s'. If a
mapping object is used for conn.execute(), then the interface
actually uses 'pyformat' = Python extended format codes,
e.g. '...WHERE name=%(name)s'. However, the API does not
presently allow the specification of more than one style in
paramstyle.
Compatibility note: The older MySQLmodule uses a similar
parameter scheme, but requires that quotes be placed around
format strings which will contain strings, dates, and similar
character data. This is not necessary for MySQLdb. It is
recommended that %s (and not '%s') be used for all parameters,
regardless of type. The interface performs all necessary
quoting.
Note that any literal percent signs in the query string passed
to execute() must be escaped, i.e. %%.
conv
A dictionary mapping MySQL types
(from FIELD_TYPE.*) to callable Python objects (usually
functions) which convert from a string to the desired type; and
mapping Python types to callable Python objects which convert
values of this type to a SQL literal string value. This is
initialized with reasonable defaults for most types. When
creating a Connection object, you can pass your own type
converter dictionary as a keyword parameter. Otherwise, it uses
a copy of MySQLdb.converters.conversions. The dictionary
includes some of the factory functions from the
DateTime module, if it is available. Several
non-standard types are returned as strings,
which is how MySQL returns all columns. For more details, see
the built-in module documentation.
As of MySQL-3.23, MySQL supports different character sets in the
server, and a new quoting function, mysql_real_escape_string().
This requires the string quoting function to be a method bound to
the connection object. MySQLdb handles this for you automatically.
However, if you feel the need to do something goofy with your strings,
you will have to modify the dictionary after opening the connection.
In practice, you should never have to worry about this. This also
applies to Unicode strings, if enabled.
Connection objects are returned by the connect() function.
commit()
If the database and the tables support
transactions, this commits the current transaction; otherwise
this method successfully does nothing.
rollback()
If the database and tables
support transactions, this rolls back (cancels) the current
transaction; otherwise a NotSupportedError is raised.
Compatibility note: The older
MySQLmodule
defines this method,
which sucessfully does nothing. This is dangerous behavior, as a
successful rollback indicates that the current transaction was
backed out, which is not true, and fails to notify the
programmer that the database now needs to be cleaned up by other
means.
cursor([cursorclass])
MySQL does not support cursors;
however, cursors are easily emulated. You can supply an
alternative cursor class as an optional parameter. If this is
not present, it defaults to the value given when creating the
connection object, or the standard Cursor class. Also see
the additional supplied cursor classes in the
usage
section.
begin()
Explicitly start a transaction. Normally you do
not need to use this: Executing a query implicitly starts a new
transaction if one is not in progress. If AUTOCOMMIT is on, you
can use begin() to temporarily turn it off. AUTOCOMMIT will
resume after the next commit() or rollback.
There are many more methods defined on the connection object which
are MySQL-specific. For more information on them, consult the internal
documentation using pydoc.
Closes the cursor. Future operations raise ProgrammingError.
If you are using
server-side cursors,
it is very important to close the cursor when you are done with
it and before creating a new one.
insert_id()
Returns the last AUTO_INCREMENT field value inserted
into the database. (Non-standard)
info()
Returns some information about the last query. Normally
you don't need to check this. With the default cursor, any MySQL
warnings cause Warning to be raised. If you are using a
cursor class without warnings, then you might want to use
this. See the MySQL docs for mysql_info(). (Non-standard)
setinputsizes()
Does nothing, successfully.
setoutputsizes()
Does nothing, successfully.
nextset()
Advances the cursor to the next result set, discarding the remaining
rows in the current result set. If there are no additional result
sets, it returns None; otherwise it returns a true value.
Note that MySQL presently doesn't support multiple result sets.
To perform a query, you first need a cursor, and then you can execute
queries on it.
c=db.cursor()
max_price=5
c.execute("""SELECT spam, eggs, sausage FROM breakfast
WHERE price < %s""", (max_price,))
In this example, max_price=5 Why, then, use %s in the
string? Because MySQLdb will convert it to a SQL literal value, which
is the string '5'. When it's finished, the query will actually say,
"...WHERE price < 5".
Why the tuple? Because the DB API requires you to pass in any
parameters as a sequence.
And now, the results:
>>> c.fetchone()
(3L, 2L, 0L)
Quite unlike the _mysql example, this returns a single tuple,
which is the row, and the values are properly converted by default...
except... What's with the L's?
As mentioned earlier, while MySQL's INTEGER column translates
perfectly into a Python integer, UNSIGNED INTEGER could overflow, so
these values are converted to Python long integers instead. Prior to
Python 1.6, long integers retained the L when converted to strings
with str(). In 1.6 and later, str() does not include the L.
Of course, the L always prints when using repr(), which is what
has happened here.
When you are finished with a transaction, you should execute either
db.commit() or db.rollback(). If your server and tables
don't support transactions, commit() will still work, but
rollback() will raise an exception. Note carefully that these are
methods of the connection and not methods of the cursor,
even though c.execute(...) is what started the transaction.
If you wanted more rows, you could use c.fetchmany(n) or
c.fetchall(). These do exactly what you think they do. On
c.fetchmany(n), the n is optional and defaults to
c.arraysize, which is normally 100. Both of these methods return
a sequence of rows, or an empty sequence if there are no more rows.
If you use a weird cursor class, the rows themselves might not be
tuples.
Note that in contrast to the above, c.fetchone() returns None
when there are no more rows to fetch.
The only other method you are very likely to use is when you have to
do a multi-row insert:
c.executemany(
"""INSERT INTO breakfast (name, spam, eggs, sausage, price)
VALUES (%s, %s, %s, %s, %s)""",
[
("Spam and Sausage Lover's Plate", 5, 1, 8, 7.95 ),
("Not So Much Spam Plate", 3, 2, 0, 3.95 ),
("Don't Wany ANY SPAM! Plate", 0, 4, 3, 5.95 )
] )
Here we are inserting three rows of five values. Notice that there is
a mix of types (strings, ints, floats) though we still only use
%s. And also note that we only included format strings for one
row. MySQLdb picks those out and duplicates them for each row.