Last updated for pysqlite 2.0beta1.
This Usage Guide is not a tutorial on Python, SQL, or SQLite; rather, it is a topical presentation of pysqlite's feature set, with example code to demonstrate basic usage patterns. This guide is meant to be consumed in conjunction with the Python Database API Specification and the SQLite documentation.
It was originally written by David Rushby for kinterbasdb. He kindly gave the permission to adapt it for pysqlite.
No type information in cursor.description
cursor.description has a tuple with the fields (name, type_code, display_size, internal_size, precision, scale, null_ok) for each column that a query returns. The DB-API spec requires that at least name and type_code are filled, but at the time cursor.description is built, pysqlite cannot determine any types, yet. So, the only field of cursor.description that pysqlite fills is name. All other fields are set to None.
Cursor class
nextset method
This method is not implemented because the database engine does not support opening multiple result sets simultaneously with a single cursor.
Cursor class
arraysize attribute
As required by the spec, the value of this attribute is observed with respect to the fetchmany method. However, changing the value of this attribute does not make any difference in fetch efficiency because the database engine only supports fetching a single row at a time.
setinputsizes method
Although this method is present, it does nothing, as allowed by the spec.
setoutputsize method
Although this method is present, it does nothing, as allowed by the spec.
pysqlite offers a large feature set beyond the minimal requirements of the Python DB API. Most of these extensions are documented in the section of this document entitled Native Database Engine Features and Extensions Beyond the Python DB API.
connect function
The parameter database refers to the database file for the SQLite database. It's a normal filesystem path and you can use absolute or relative path names.
The connect function supports the following optional keyword arguments in addition to those required by the spec:
timeout - When a database is accessed by multiple connections, and
one of the processes modifies the database, the SQLite database is locked until that transaction is committed. The timeout parameter specifies how long the connection should wait for the lock to go away until raising an exception. The default for the timeout parameter is 5.0 (five seconds).
autocommit - Some users don't want to work with transactions, or want to write a layer on top of pysqlite that implementes transaction management differently than pysqlite. With autocommit=True, pysqlite does not issue BEGIN statements automatically any more. Note that you can toggle the autocommit attribute of connections also.
Example:
prepareProtocol - SQLite natively supports only the types TEXT (str and unicode), INTEGER (int and long), FLOAT (float), BLOB (buffer) and NULL (None). The names in brackets are the corresponding Python types.
For using other Python types with SQLite, you need to add support to them using pysqlite. You can do that by giving your custom Python type a __conform__ method with this signature:
def __conform__(self, protocol):
...
The Python type then can check if protocol is an instance of pysqlite.dbapi2.PrepareProtocol and adapt itself to one of SQLite's supported Python types: str, unicode, int, long, float, buffer. Or return None if it cannot adapt itself.
Normally, it's more practical to extend pysqlite's PrepareProtocol instead so it supports your type.
For example if you wanted to add support for the standard Python datetime.datetime type to pysqlite, you could do it like this:
class MyProtocol:
def __adapt__(self, val):
if type(val) is datetime.datetime:
return time.mktime(val.timetuple())
con = sqlite.connect("mydb", prepareProtocol=MyProtocol())
cur = con.cursor()
cur.execute("insert into mytable(ts) values (?)", (datetime.datetime.now(),))
detect_types - SQLite natively supports only the types TEXT, INTEGER, FLOAT, BLOB and NULL. If you want to use other types, like date/time related ones, you have to add support for them yourself. The detect_types parameter and the converters attribute of connections allow you to easily do that.
detect_types defaults to 0 (i. e. off, no type detection), you can set it to any combination of PARSE_DECLTYPES and PARSE_COLNAMES to turn type detection on.
sqlite.PARSE_DECLTYPES - This makes pysqlite parse the declared type for each column it returns. It will parse out the first word of the declared type, i. e. for "integer primary key", it will parse out "integer". Then for that column, it will look into the converters property of the connection (a dictionary that you can modify at will) and use the converter function registered for that type there.
Example:
sqlite.PARSE_COLNAMES - This makes pysqlite parse the column name for each column it returns. It will look for a string formed [mytype] in there, and then decide that 'mytype' is the type of the column. It will try to find an entry of 'mytype' in the converters dictionary and then use the converter function found there to return the value. The column name found in cursor.description is only the first word of the column name, i. e. if you use something like 'as "x [datetime]"' in your SQL, then pysqlite will parse out everything until the first blank for the column name: the column name would simply be "x".
Example:
check_same_thread - SQLite connections/cursors can only safely be used in the same thread they were created in. pysqlite checks for this each time it would do a call to the SQLite engine. If you are confident that you are ensuring safety otherwise, you can disable that checks by setting check_same_thread to False.
factory - By default, pysqlite uses the Connection class for the connect call. You can, however, subclass the Connection class and make .connect() use your class instead by providing your class for the factory parameter.
Example:
Connection class
autocommit attribute (read-write) Some users don't want to work with transactions, or want to write a layer on top of pysqlite that implementes transaction management differently than pysqlite. With autocommit=True, pysqlite does not issue BEGIN statements automatically any more. Note that you set the autocommit value at connection creation time using the autocommit parameter to connect also.
converters attribute (read-write) This dictionary maps type names to converter functions, it's empty by default, and you can replace it with your own dictionary or modify it.
cursor method - The cursor method accepts a single optional parameter: a custom cursor class extending pysqlite's Cursor class that you can adapt to your needs. Note that it is required that your custom cursor class extends pysqlite's Cursor class.
For a useful example, look at the example for the row_factory attribute of cursors.
Cursor class
execute method
pysqlite uses paramstyle = "qmark". That means if you use parametrized statements, you use the question mark as placeholder.
This is a basic example showing the use of question marks as placeholders and a parameter tuple:
pysqlite also supports paramstyle = "named". That means you can use named placeholders in the format ":name", i. e. a colon followed by the parameter name. As parameters, you then supply a mapping instead of a sequence. In the simplest case, a dictionary instead of a tuple.
The following example shows a shortcut that you can often use when using named parameters. It exploits the fact that locals() is a dictionary, too. So you can also use it as parameter for execute:
executemany method
The DB-API specifies the executemany method like this:
pysqlite, however, extends executemany so it can be used more efficiently for inserting bulk data. The second parameter to executemany can be a sequence of parameters, but it can also be an iterator returning parameters.
Example:
As generators are iterators, too, here's a much simpler, equivalent example using a generator:
rowcount attribute
Although pysqlite's Cursors implement this attribute, the database engine's own support for the determination of "rows affected"/"rows selected" is quirky.
For SELECT statements, rowcount is always None because pysqlite cannot determine the number of rows a query produced until all rows were fetched.
For DELETE statements, SQLite reports rowcount as 0 if you make a DELETE FROM table without any condition.
For executemany statements, pysqlite sums up the number of modifications into rowcount.
As required by the Python DB API Spec, the rowcount attribute "is -1 in case no executeXX() has been performed on the cursor or the rowcount of the last operation is not determinable by the interface".
row_factory attribute (read-write)
You can change this attribute to a callable that accepts the cursor and the original row as tuple and will return the real result row. This way, you can implement more advanced ways of returning results, like ones that can also access columns by name.
Example:
This brief tutorial aims to get the reader started by demonstrating elementary usage of pysqlite. It is not a comprehensive Python Database API tutorial, nor is it comprehensive in its coverage of anything else.
Example 1
Connecting to a database file mydb:
from pysqlite2 import dbapi2 as sqlite
con = sqlite.connect("mydb")Example 2
Creating an in-memory database:
from pysqlite2 import dbapi2 as sqlite
con = sqlite.connect(":memory:")
For this section, we have a database mydb defined and populated by the following SQL code:
create table people
(
name_last varchar(20),
age integer
);
insert into people (name_last, age) values ('Yeltsin', 72);
insert into people (name_last, age) values ('Putin', 51);
Example 1
This example shows the simplest way to print the entire contents of the people table:
Sample output:
[(u'Putin', 51), (u'Yeltsin', 72)]
Example 2
Here's another trivial example that demonstrates various ways of fetching a single row at a time from a SELECT-cursor:
Sample output:
Putin is 51 years old. Yeltsin is 72 years old. Putin is 51 years old. Yeltsin is 72 years old.
Example 3
The following program is a simplistic table printer (applied in this example to people)
Sample output:
name_last age ------------------------------------------------------------------------------ Putin 51 Yeltsin 72
Example 4
Let's insert more people into the people table:
Note the use of a parameterized SQL statement above. When dealing with repetitive statements, this is much faster and less error-prone than assembling each SQL statement manually.
It's also worth noting that in the example above, the code:
It's also worth noting that in the example above, the code:
could be rewritten as:
After running Example 4, the table printer from Example 3 would print:
name_last age ------------------------------------------------------------------------------ Putin 51 Lebed 53 Zhirinovsky 57 Yeltsin 72
SQLite supports user-defined functions. Using pysqlite, you can create new functions with the connection's create_function method:
def create_function(self, name, numparams, func)
- name
- the name of your function in SQL
- numparams
- the number of parameters your function accepts, -1 if it accepts any number of parameters
- func
- the Python function
The function can return any of pysqlite's supported SQLite types: unicode, str, int, long, float, buffer and None. The function should never raise an exception.
Example:
def md5sum(t):
return md5.md5(t).hexdigest()
con = sqlite.connect(":memory:")
con.create_function("md5", 1, md5sum)
cur = con.cursor()
cur.execute("select md5(?)", ("foo",))
print cur.fetchone()[0]
SQLite supports user-defined aggregate functions. Using pysqlite, you can create new aggregate functions with the connection's create_aggregate method.
def create_aggregate(self, name, numparams, aggregate_class)The aggregate class must implement a step method, which accepts the number of parameters defined in create_aggregate, and a finalize method which will return the final result of the aggregate.
The finalize method can return any of pysqlite's supported SQLite types: unicode, str, int, long, float, buffer and None. The aggregate class's methods should never raise any exception.
Example:
from pysqlite2 import dbapi2 as sqlite
class MySum:
def __init__(self):
self.count = 0
def step(self, value):
self.count += value
def finalize(self):
return self.count
con = sqlite.connect(":memory:")
con.create_aggregate("mysum", 1, MySum)
cur = con.cursor()
cur.execute("create table test(i)")
cur.execute("insert into test(i) values (1)")
cur.execute("insert into test(i) values (2)")
cur.execute("select mysum(i) from test")
print cur.fetchone()[0]