Last updated for pysqlite 2.0.2
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.
No type objects
Consequently, there are also no type objects STRING, BINARY, NUMBER, DATETIME, ROWID at module-level. They would be useless.
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).
isolation_level - pysqlite will by default open transactions with a "BEGIN" statement, when it encounters a DML statement like INSERT/UPDATE/DELETE/REPLACE. Some users don't want pysqlite to implicitly open transactions for them - they want an autocommit mode. Other users want pysqlite to open different kinds of transactions, like with "BEGIN IMMEDIATE". See 5. Controlling Transactions for a more detailed explanation.
Note that you can also switch to a different isolation level by setting the isolation_level property of connections.
detect_types - SQLite natively supports only the types TEXT, INTEGER, FLOAT, BLOB and NULL. If you want to use other types, like you have to add support for them yourself. The detect_types parameter and the using custom converters registered with the module-level register_converter function 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.
Consult the section 4. SQlite and Python types of this manual for details.
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 pysqlite's converters dictionary and use the converter function registered for that type there.
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".
The following example uses the column name timestamp, which is already registered by default in the converters dictionary with an appropriate converter!
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:
register_converter function - register_converter(typename, callable) registers a callable to convert a bytestring from the database into a custom Python type. The converter will be invoked for all database values that are of the type typename. Confer the parameter detect_types of the connect method for how the type detection works.
register_adapter function - register_adapter(type, callable) registers a callable to convert the custom Python type into one of SQLite's supported types. The callable accepts as single parameter the Python value, and must return a value of the following types: int, long, float, str (UTF-8 encoded), unicode or buffer.
Connection class
isolation_level attribute (read-write)
Get or set the current isolation level: None for autocommit mode or one of "DEFERRED", "IMMEDIATE" or "EXLUSIVE". See 5. Controlling Transactions for a more detailed explanation.
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:
execute will only execute a single SQL statement. If you try to execute more than one statement with it, it will raise a Warning. Use executescript if want to execute multiple SQL statements with one call.
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:
executemany will only execute a single SQL statement. If you try to execute more than one statement with it, it will raise a Warning. Use executescript if want to execute multiple SQL statements with one call.
executescript method
.executemany(sqlscript)This is a nonstandard convenience method for executing multiple SQL statements at once. It issues a COMMIT statement before, then executes the SQL script it gets as a parameter.
The SQL script sqlscript can be a bytestring or a Unicode string.
Example:
from pysqlite2 import dbapi2 as sqlite
con = sqlite.connect(":memory:")
cur = con.cursor()
cur.executescript("""
create table person(
firstname,
lastname,
age
);
create table book(
title,
author,
published
);
insert into book(title, author, published)
values (
'Dirk Gently''s Holistic Detective Agency
'Douglas Adams',
1987
);
""")
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:
from pysqlite2 import dbapi2 as sqlite
import md5
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]
http://sqlite.org/datatype3.html
SQLite natively supports the following types: NULL, INTEGER, REAL, TEXT, BLOB.
The following Python types can thus be sent to SQLite without any problem:
Python type | SQLite type |
---|---|
NoneType | NULL |
int | INTEGER |
long | INTEGER |
float | REAL |
str (utf-8 encoded) | TEXT |
unicode | TEXT |
buffer | BLOB |
This is how SQLite types are converted to Python types by default:
SQLite type | Python type |
---|---|
NULL | NoneType |
INTEGER | int or long, depending on size |
REAL | float |
TEXT | unicode |
BLOB | buffer |
pysqlite's type system is extensible in both ways: you can store additional Python types in a SQLite database via object adaptation, and you can let pysqlite convert SQLite types to different Python types via pysqlite's converters.
Like described before, SQLite supports only a limited set of types natively. To use other Python types with SQLite, you must adapt them to one of pysqlite's supported types for SQLite. So, one of NoneType, int, long, float, str, unicode, buffer.
pysqlite uses the Python object adaptation, like described in PEP 246 for this. The protocol to use is PrepareProtocol.
There are two ways to enable pysqlite to adapt a custom Python type to one of the supported ones.
This is a good approach if you write the class yourself. Let's suppose you have a class like this:
class Point(object):
def __init__(self, x, y):
self.x, self.y = x, y
Now you want to store the point in a single SQLite column. You'll have to choose one of the supported types first that you use to represent the point in. Let's just use str and separate the coordinates using a semicolon. Then you need to give your class a method __conform__(self, protocol) which must return the converted value. The parameter protocol will be PrepareProtocol.
The other possibility is to create a function that converts the type to the string representation and register the function with register_adapter.
The type/class to adapt must be a new-style class, i. e. it must have object as one of its bases!!!
pysqlite has two default adapters for Python's builtin date and datetime types. Now let's suppose we want to store datetime objects not in ISO representation, but as Unix timestamp.
Now that's all nice and dandy that you can send custom Python types to SQLite. But to make it really useful we need to make the Python to SQLite to Python roundtrip work.
Enter pysqlite converters.
Let's go back to the Point class. We stored the x and y coordinates separated via semicolons as strings in SQLite.
Let's first define a converter function that accepts the string as a parameter and constructs a Point object from it.
!!! Note that converter functions always get called with a string, no matter under which data type you sent the value to SQLite !!!
def convert_point(s):
x, y = map(float, s.split(";"))
return Point(x, y)
Now you need to make pysqlite know that what you select from the database is actually a point. There are two ways of doing this:
- Implicitly via the declared type
- Explicitly via the column name
Both ways are described in section 1.4 Extensions and Caveats in the paragraphs describing the connect function, and specifically the meaning of the detect_types parameter.
The following example illustrates both ways.
pysqlite has default adapters for the date and datetime types in the datetime module. They will be sent as ISO dates/ISO timestamps to SQLite.
pysqlite has default converters registered under the name "date" for datetime.date and under the name "timestamp" for datetime.datetime.
This way, you can use date/timestamps from pysqlite without any additional fiddling in most cases. The format of the adapters is also compatible with the experimental SQLite date/time functions.
The following example demonstrates this.
By default, pysqlite opens transactions implicitly before a DML statement (INSERT/UPDATE/DELETE/REPLACE), and commits transactions implicitly before a non-DML, non-DQL statement (i. e. anything other than SELECT/INSERT/UPDATE/DELETE/REPLACE).
So if you are within a transaction, and issue a command like CREATE TABLE ..., VACUUM, PRAGMA, pysqlite will commit implicitly before executing that command. There are two reasons for doing that. The first is that most of these commands don't work within transactions. The other reason is that pysqlite needs to keep track of the transaction state (if a transaction is active or not).
You can control which kind of "BEGIN" statements pysqlite implicitly executes (or none at all) via the isolation_level parameter to the connect call, or via the isolation_level property of connections.
If you want autocommit mode, then set isolation_level to None.
Otherwise leave it at it's default, which will result in a plain "BEGIN" statement, or set it to one of SQLite's supported isolation levels: DEFERRED, IMMEDIATE or EXCLUSIVE.