blob: 8ccb0ab2ab1f82c7583cd532da0ac85bac38a704 [file] [log] [blame]
Georg Brandl8ec7f652007-08-15 14:28:01 +00001:mod:`sqlite3` --- DB-API 2.0 interface for SQLite databases
2============================================================
3
4.. module:: sqlite3
5 :synopsis: A DB-API 2.0 implementation using SQLite 3.x.
6.. sectionauthor:: Gerhard Häring <gh@ghaering.de>
7
8
9.. versionadded:: 2.5
10
11SQLite is a C library that provides a lightweight disk-based database that
12doesn't require a separate server process and allows accessing the database
13using a nonstandard variant of the SQL query language. Some applications can use
14SQLite for internal data storage. It's also possible to prototype an
15application using SQLite and then port the code to a larger database such as
16PostgreSQL or Oracle.
17
Georg Brandl498a9b32009-05-20 18:31:14 +000018sqlite3 was written by Gerhard Häring and provides a SQL interface compliant
Georg Brandl8ec7f652007-08-15 14:28:01 +000019with the DB-API 2.0 specification described by :pep:`249`.
20
21To use the module, you must first create a :class:`Connection` object that
22represents the database. Here the data will be stored in the
23:file:`/tmp/example` file::
24
25 conn = sqlite3.connect('/tmp/example')
26
27You can also supply the special name ``:memory:`` to create a database in RAM.
28
29Once you have a :class:`Connection`, you can create a :class:`Cursor` object
Georg Brandl26497d92008-10-08 17:20:20 +000030and call its :meth:`~Cursor.execute` method to perform SQL commands::
Georg Brandl8ec7f652007-08-15 14:28:01 +000031
32 c = conn.cursor()
33
34 # Create table
35 c.execute('''create table stocks
36 (date text, trans text, symbol text,
37 qty real, price real)''')
38
39 # Insert a row of data
40 c.execute("""insert into stocks
41 values ('2006-01-05','BUY','RHAT',100,35.14)""")
42
43 # Save (commit) the changes
44 conn.commit()
45
46 # We can also close the cursor if we are done with it
47 c.close()
48
49Usually your SQL operations will need to use values from Python variables. You
50shouldn't assemble your query using Python's string operations because doing so
51is insecure; it makes your program vulnerable to an SQL injection attack.
52
53Instead, use the DB-API's parameter substitution. Put ``?`` as a placeholder
54wherever you want to use a value, and then provide a tuple of values as the
Georg Brandl498a9b32009-05-20 18:31:14 +000055second argument to the cursor's :meth:`~Cursor.execute` method. (Other database
56modules may use a different placeholder, such as ``%s`` or ``:1``.) For
57example::
Georg Brandl8ec7f652007-08-15 14:28:01 +000058
59 # Never do this -- insecure!
60 symbol = 'IBM'
61 c.execute("... where symbol = '%s'" % symbol)
62
63 # Do this instead
64 t = (symbol,)
65 c.execute('select * from stocks where symbol=?', t)
66
67 # Larger example
Georg Brandlb9bfea72008-11-06 10:19:11 +000068 for t in [('2006-03-28', 'BUY', 'IBM', 1000, 45.00),
Georg Brandl8ec7f652007-08-15 14:28:01 +000069 ('2006-04-05', 'BUY', 'MSOFT', 1000, 72.00),
70 ('2006-04-06', 'SELL', 'IBM', 500, 53.00),
Georg Brandlb9bfea72008-11-06 10:19:11 +000071 ]:
Georg Brandl8ec7f652007-08-15 14:28:01 +000072 c.execute('insert into stocks values (?,?,?,?,?)', t)
73
Georg Brandle7a09902007-10-21 12:10:28 +000074To retrieve data after executing a SELECT statement, you can either treat the
Georg Brandl26497d92008-10-08 17:20:20 +000075cursor as an :term:`iterator`, call the cursor's :meth:`~Cursor.fetchone` method to
76retrieve a single matching row, or call :meth:`~Cursor.fetchall` to get a list of the
Georg Brandle7a09902007-10-21 12:10:28 +000077matching rows.
Georg Brandl8ec7f652007-08-15 14:28:01 +000078
79This example uses the iterator form::
80
81 >>> c = conn.cursor()
82 >>> c.execute('select * from stocks order by price')
83 >>> for row in c:
84 ... print row
85 ...
Mark Dickinson6b87f112009-11-24 14:27:02 +000086 (u'2006-01-05', u'BUY', u'RHAT', 100, 35.14)
Georg Brandl8ec7f652007-08-15 14:28:01 +000087 (u'2006-03-28', u'BUY', u'IBM', 1000, 45.0)
88 (u'2006-04-06', u'SELL', u'IBM', 500, 53.0)
89 (u'2006-04-05', u'BUY', u'MSOFT', 1000, 72.0)
90 >>>
91
92
93.. seealso::
94
Michael Foordabe63312010-03-02 14:22:15 +000095 http://code.google.com/p/pysqlite/
Georg Brandl498a9b32009-05-20 18:31:14 +000096 The pysqlite web page -- sqlite3 is developed externally under the name
97 "pysqlite".
Georg Brandl8ec7f652007-08-15 14:28:01 +000098
99 http://www.sqlite.org
Georg Brandl498a9b32009-05-20 18:31:14 +0000100 The SQLite web page; the documentation describes the syntax and the
101 available data types for the supported SQL dialect.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000102
103 :pep:`249` - Database API Specification 2.0
104 PEP written by Marc-André Lemburg.
105
106
107.. _sqlite3-module-contents:
108
109Module functions and constants
110------------------------------
111
112
113.. data:: PARSE_DECLTYPES
114
115 This constant is meant to be used with the *detect_types* parameter of the
116 :func:`connect` function.
117
118 Setting it makes the :mod:`sqlite3` module parse the declared type for each
Gerhard Häringe11c9b32008-05-04 13:42:44 +0000119 column it returns. It will parse out the first word of the declared type,
120 i. e. for "integer primary key", it will parse out "integer", or for
121 "number(10)" it will parse out "number". Then for that column, it will look
122 into the converters dictionary and use the converter function registered for
123 that type there.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000124
125
126.. data:: PARSE_COLNAMES
127
128 This constant is meant to be used with the *detect_types* parameter of the
129 :func:`connect` function.
130
131 Setting this makes the SQLite interface parse the column name for each column it
132 returns. It will look for a string formed [mytype] in there, and then decide
133 that 'mytype' is the type of the column. It will try to find an entry of
134 'mytype' in the converters dictionary and then use the converter function found
Georg Brandl26497d92008-10-08 17:20:20 +0000135 there to return the value. The column name found in :attr:`Cursor.description`
Georg Brandl8ec7f652007-08-15 14:28:01 +0000136 is only the first word of the column name, i. e. if you use something like
137 ``'as "x [datetime]"'`` in your SQL, then we will parse out everything until the
138 first blank for the column name: the column name would simply be "x".
139
140
141.. function:: connect(database[, timeout, isolation_level, detect_types, factory])
142
143 Opens a connection to the SQLite database file *database*. You can use
144 ``":memory:"`` to open a database connection to a database that resides in RAM
145 instead of on disk.
146
147 When a database is accessed by multiple connections, and one of the processes
148 modifies the database, the SQLite database is locked until that transaction is
149 committed. The *timeout* parameter specifies how long the connection should wait
150 for the lock to go away until raising an exception. The default for the timeout
151 parameter is 5.0 (five seconds).
152
153 For the *isolation_level* parameter, please see the
154 :attr:`Connection.isolation_level` property of :class:`Connection` objects.
155
156 SQLite natively supports only the types TEXT, INTEGER, FLOAT, BLOB and NULL. If
157 you want to use other types you must add support for them yourself. The
158 *detect_types* parameter and the using custom **converters** registered with the
159 module-level :func:`register_converter` function allow you to easily do that.
160
161 *detect_types* defaults to 0 (i. e. off, no type detection), you can set it to
162 any combination of :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES` to turn
163 type detection on.
164
165 By default, the :mod:`sqlite3` module uses its :class:`Connection` class for the
166 connect call. You can, however, subclass the :class:`Connection` class and make
167 :func:`connect` use your class instead by providing your class for the *factory*
168 parameter.
169
170 Consult the section :ref:`sqlite3-types` of this manual for details.
171
172 The :mod:`sqlite3` module internally uses a statement cache to avoid SQL parsing
173 overhead. If you want to explicitly set the number of statements that are cached
174 for the connection, you can set the *cached_statements* parameter. The currently
175 implemented default is to cache 100 statements.
176
177
178.. function:: register_converter(typename, callable)
179
180 Registers a callable to convert a bytestring from the database into a custom
181 Python type. The callable will be invoked for all database values that are of
182 the type *typename*. Confer the parameter *detect_types* of the :func:`connect`
183 function for how the type detection works. Note that the case of *typename* and
184 the name of the type in your query must match!
185
186
187.. function:: register_adapter(type, callable)
188
189 Registers a callable to convert the custom Python type *type* into one of
190 SQLite's supported types. The callable *callable* accepts as single parameter
191 the Python value, and must return a value of the following types: int, long,
192 float, str (UTF-8 encoded), unicode or buffer.
193
194
195.. function:: complete_statement(sql)
196
197 Returns :const:`True` if the string *sql* contains one or more complete SQL
198 statements terminated by semicolons. It does not verify that the SQL is
199 syntactically correct, only that there are no unclosed string literals and the
200 statement is terminated by a semicolon.
201
202 This can be used to build a shell for SQLite, as in the following example:
203
204
205 .. literalinclude:: ../includes/sqlite3/complete_statement.py
206
207
208.. function:: enable_callback_tracebacks(flag)
209
210 By default you will not get any tracebacks in user-defined functions,
211 aggregates, converters, authorizer callbacks etc. If you want to debug them, you
212 can call this function with *flag* as True. Afterwards, you will get tracebacks
213 from callbacks on ``sys.stderr``. Use :const:`False` to disable the feature
214 again.
215
216
217.. _sqlite3-connection-objects:
218
219Connection Objects
220------------------
221
Georg Brandl26497d92008-10-08 17:20:20 +0000222.. class:: Connection
223
224 A SQLite database connection has the following attributes and methods:
Georg Brandl8ec7f652007-08-15 14:28:01 +0000225
226.. attribute:: Connection.isolation_level
227
Benjamin Peterson78f98a42008-11-26 17:39:17 +0000228 Get or set the current isolation level. :const:`None` for autocommit mode or
229 one of "DEFERRED", "IMMEDIATE" or "EXCLUSIVE". See section
Georg Brandl8ec7f652007-08-15 14:28:01 +0000230 :ref:`sqlite3-controlling-transactions` for a more detailed explanation.
231
232
233.. method:: Connection.cursor([cursorClass])
234
235 The cursor method accepts a single optional parameter *cursorClass*. If
236 supplied, this must be a custom cursor class that extends
237 :class:`sqlite3.Cursor`.
238
239
Gerhard Häring41309302008-03-29 01:27:37 +0000240.. method:: Connection.commit()
241
242 This method commits the current transaction. If you don't call this method,
Georg Brandl26497d92008-10-08 17:20:20 +0000243 anything you did since the last call to ``commit()`` is not visible from from
Gerhard Häring41309302008-03-29 01:27:37 +0000244 other database connections. If you wonder why you don't see the data you've
245 written to the database, please check you didn't forget to call this method.
246
247.. method:: Connection.rollback()
248
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000249 This method rolls back any changes to the database since the last call to
Gerhard Häring41309302008-03-29 01:27:37 +0000250 :meth:`commit`.
251
252.. method:: Connection.close()
253
254 This closes the database connection. Note that this does not automatically
255 call :meth:`commit`. If you just close your database connection without
256 calling :meth:`commit` first, your changes will be lost!
257
Georg Brandl8ec7f652007-08-15 14:28:01 +0000258.. method:: Connection.execute(sql, [parameters])
259
260 This is a nonstandard shortcut that creates an intermediate cursor object by
Ezio Melottia68f7b82010-02-14 02:50:23 +0000261 calling the cursor method, then calls the cursor's
262 :meth:`execute<Cursor.execute>` method with the parameters given.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000263
264
265.. method:: Connection.executemany(sql, [parameters])
266
267 This is a nonstandard shortcut that creates an intermediate cursor object by
Ezio Melottia68f7b82010-02-14 02:50:23 +0000268 calling the cursor method, then calls the cursor's
269 :meth:`executemany<Cursor.executemany>` method with the parameters given.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000270
Georg Brandl8ec7f652007-08-15 14:28:01 +0000271.. method:: Connection.executescript(sql_script)
272
273 This is a nonstandard shortcut that creates an intermediate cursor object by
Ezio Melottia68f7b82010-02-14 02:50:23 +0000274 calling the cursor method, then calls the cursor's
275 :meth:`executescript<Cursor.executescript>` method with the parameters
276 given.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000277
278
279.. method:: Connection.create_function(name, num_params, func)
280
281 Creates a user-defined function that you can later use from within SQL
282 statements under the function name *name*. *num_params* is the number of
283 parameters the function accepts, and *func* is a Python callable that is called
284 as the SQL function.
285
286 The function can return any of the types supported by SQLite: unicode, str, int,
287 long, float, buffer and None.
288
289 Example:
290
291 .. literalinclude:: ../includes/sqlite3/md5func.py
292
293
294.. method:: Connection.create_aggregate(name, num_params, aggregate_class)
295
296 Creates a user-defined aggregate function.
297
298 The aggregate class must implement a ``step`` method, which accepts the number
299 of parameters *num_params*, and a ``finalize`` method which will return the
300 final result of the aggregate.
301
302 The ``finalize`` method can return any of the types supported by SQLite:
303 unicode, str, int, long, float, buffer and None.
304
305 Example:
306
307 .. literalinclude:: ../includes/sqlite3/mysumaggr.py
308
309
310.. method:: Connection.create_collation(name, callable)
311
312 Creates a collation with the specified *name* and *callable*. The callable will
313 be passed two string arguments. It should return -1 if the first is ordered
314 lower than the second, 0 if they are ordered equal and 1 if the first is ordered
315 higher than the second. Note that this controls sorting (ORDER BY in SQL) so
316 your comparisons don't affect other SQL operations.
317
318 Note that the callable will get its parameters as Python bytestrings, which will
319 normally be encoded in UTF-8.
320
321 The following example shows a custom collation that sorts "the wrong way":
322
323 .. literalinclude:: ../includes/sqlite3/collation_reverse.py
324
325 To remove a collation, call ``create_collation`` with None as callable::
326
327 con.create_collation("reverse", None)
328
329
330.. method:: Connection.interrupt()
331
332 You can call this method from a different thread to abort any queries that might
333 be executing on the connection. The query will then abort and the caller will
334 get an exception.
335
336
337.. method:: Connection.set_authorizer(authorizer_callback)
338
339 This routine registers a callback. The callback is invoked for each attempt to
340 access a column of a table in the database. The callback should return
341 :const:`SQLITE_OK` if access is allowed, :const:`SQLITE_DENY` if the entire SQL
342 statement should be aborted with an error and :const:`SQLITE_IGNORE` if the
343 column should be treated as a NULL value. These constants are available in the
344 :mod:`sqlite3` module.
345
346 The first argument to the callback signifies what kind of operation is to be
347 authorized. The second and third argument will be arguments or :const:`None`
348 depending on the first argument. The 4th argument is the name of the database
349 ("main", "temp", etc.) if applicable. The 5th argument is the name of the
350 inner-most trigger or view that is responsible for the access attempt or
351 :const:`None` if this access attempt is directly from input SQL code.
352
353 Please consult the SQLite documentation about the possible values for the first
354 argument and the meaning of the second and third argument depending on the first
355 one. All necessary constants are available in the :mod:`sqlite3` module.
356
357
Gerhard Häring41309302008-03-29 01:27:37 +0000358.. method:: Connection.set_progress_handler(handler, n)
359
360 .. versionadded:: 2.6
361
362 This routine registers a callback. The callback is invoked for every *n*
363 instructions of the SQLite virtual machine. This is useful if you want to
364 get called from SQLite during long-running operations, for example to update
365 a GUI.
366
367 If you want to clear any previously installed progress handler, call the
368 method with :const:`None` for *handler*.
369
370
Georg Brandl8ec7f652007-08-15 14:28:01 +0000371.. attribute:: Connection.row_factory
372
373 You can change this attribute to a callable that accepts the cursor and the
374 original row as a tuple and will return the real result row. This way, you can
375 implement more advanced ways of returning results, such as returning an object
376 that can also access columns by name.
377
378 Example:
379
380 .. literalinclude:: ../includes/sqlite3/row_factory.py
381
382 If returning a tuple doesn't suffice and you want name-based access to
383 columns, you should consider setting :attr:`row_factory` to the
384 highly-optimized :class:`sqlite3.Row` type. :class:`Row` provides both
385 index-based and case-insensitive name-based access to columns with almost no
386 memory overhead. It will probably be better than your own custom
387 dictionary-based approach or even a db_row based solution.
388
Georg Brandlb19be572007-12-29 10:57:00 +0000389 .. XXX what's a db_row-based solution?
Georg Brandl8ec7f652007-08-15 14:28:01 +0000390
391
392.. attribute:: Connection.text_factory
393
Georg Brandl26497d92008-10-08 17:20:20 +0000394 Using this attribute you can control what objects are returned for the ``TEXT``
395 data type. By default, this attribute is set to :class:`unicode` and the
396 :mod:`sqlite3` module will return Unicode objects for ``TEXT``. If you want to
Georg Brandl8ec7f652007-08-15 14:28:01 +0000397 return bytestrings instead, you can set it to :class:`str`.
398
399 For efficiency reasons, there's also a way to return Unicode objects only for
400 non-ASCII data, and bytestrings otherwise. To activate it, set this attribute to
401 :const:`sqlite3.OptimizedUnicode`.
402
403 You can also set it to any other callable that accepts a single bytestring
404 parameter and returns the resulting object.
405
406 See the following example code for illustration:
407
408 .. literalinclude:: ../includes/sqlite3/text_factory.py
409
410
411.. attribute:: Connection.total_changes
412
413 Returns the total number of database rows that have been modified, inserted, or
414 deleted since the database connection was opened.
415
416
Gregory P. Smithb9803422008-03-28 08:32:09 +0000417.. attribute:: Connection.iterdump
418
419 Returns an iterator to dump the database in an SQL text format. Useful when
420 saving an in-memory database for later restoration. This function provides
421 the same capabilities as the :kbd:`.dump` command in the :program:`sqlite3`
422 shell.
423
424 .. versionadded:: 2.6
425
426 Example::
427
428 # Convert file existing_db.db to SQL dump file dump.sql
Benjamin Petersona7b55a32009-02-20 03:31:23 +0000429 import sqlite3, os
Gregory P. Smithb9803422008-03-28 08:32:09 +0000430
431 con = sqlite3.connect('existing_db.db')
Georg Brandlb9bfea72008-11-06 10:19:11 +0000432 with open('dump.sql', 'w') as f:
433 for line in con.iterdump():
434 f.write('%s\n' % line)
Gregory P. Smithb9803422008-03-28 08:32:09 +0000435
436
Georg Brandl8ec7f652007-08-15 14:28:01 +0000437.. _sqlite3-cursor-objects:
438
439Cursor Objects
440--------------
441
Georg Brandl26497d92008-10-08 17:20:20 +0000442.. class:: Cursor
Georg Brandl8ec7f652007-08-15 14:28:01 +0000443
Georg Brandl26497d92008-10-08 17:20:20 +0000444 A SQLite database cursor has the following attributes and methods:
Georg Brandl8ec7f652007-08-15 14:28:01 +0000445
446.. method:: Cursor.execute(sql, [parameters])
447
Georg Brandlf558d2e2008-01-19 20:53:07 +0000448 Executes an SQL statement. The SQL statement may be parametrized (i. e.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000449 placeholders instead of SQL literals). The :mod:`sqlite3` module supports two
450 kinds of placeholders: question marks (qmark style) and named placeholders
451 (named style).
452
453 This example shows how to use parameters with qmark style:
454
455 .. literalinclude:: ../includes/sqlite3/execute_1.py
456
457 This example shows how to use the named style:
458
459 .. literalinclude:: ../includes/sqlite3/execute_2.py
460
461 :meth:`execute` will only execute a single SQL statement. If you try to execute
462 more than one statement with it, it will raise a Warning. Use
463 :meth:`executescript` if you want to execute multiple SQL statements with one
464 call.
465
466
467.. method:: Cursor.executemany(sql, seq_of_parameters)
468
Georg Brandlf558d2e2008-01-19 20:53:07 +0000469 Executes an SQL command against all parameter sequences or mappings found in
Georg Brandle7a09902007-10-21 12:10:28 +0000470 the sequence *sql*. The :mod:`sqlite3` module also allows using an
471 :term:`iterator` yielding parameters instead of a sequence.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000472
473 .. literalinclude:: ../includes/sqlite3/executemany_1.py
474
Georg Brandlcf3fb252007-10-21 10:52:38 +0000475 Here's a shorter example using a :term:`generator`:
Georg Brandl8ec7f652007-08-15 14:28:01 +0000476
477 .. literalinclude:: ../includes/sqlite3/executemany_2.py
478
479
480.. method:: Cursor.executescript(sql_script)
481
482 This is a nonstandard convenience method for executing multiple SQL statements
Georg Brandl26497d92008-10-08 17:20:20 +0000483 at once. It issues a ``COMMIT`` statement first, then executes the SQL script it
Georg Brandl8ec7f652007-08-15 14:28:01 +0000484 gets as a parameter.
485
486 *sql_script* can be a bytestring or a Unicode string.
487
488 Example:
489
490 .. literalinclude:: ../includes/sqlite3/executescript.py
491
492
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000493.. method:: Cursor.fetchone()
494
Georg Brandlf558d2e2008-01-19 20:53:07 +0000495 Fetches the next row of a query result set, returning a single sequence,
Georg Brandl26497d92008-10-08 17:20:20 +0000496 or :const:`None` when no more data is available.
Georg Brandlf558d2e2008-01-19 20:53:07 +0000497
498
499.. method:: Cursor.fetchmany([size=cursor.arraysize])
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000500
Georg Brandlf558d2e2008-01-19 20:53:07 +0000501 Fetches the next set of rows of a query result, returning a list. An empty
502 list is returned when no more rows are available.
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000503
Georg Brandlf558d2e2008-01-19 20:53:07 +0000504 The number of rows to fetch per call is specified by the *size* parameter.
505 If it is not given, the cursor's arraysize determines the number of rows
506 to be fetched. The method should try to fetch as many rows as indicated by
507 the size parameter. If this is not possible due to the specified number of
508 rows not being available, fewer rows may be returned.
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000509
Georg Brandlf558d2e2008-01-19 20:53:07 +0000510 Note there are performance considerations involved with the *size* parameter.
511 For optimal performance, it is usually best to use the arraysize attribute.
512 If the *size* parameter is used, then it is best for it to retain the same
513 value from one :meth:`fetchmany` call to the next.
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000514
515.. method:: Cursor.fetchall()
Georg Brandlf558d2e2008-01-19 20:53:07 +0000516
517 Fetches all (remaining) rows of a query result, returning a list. Note that
518 the cursor's arraysize attribute can affect the performance of this operation.
519 An empty list is returned when no rows are available.
520
521
Georg Brandl8ec7f652007-08-15 14:28:01 +0000522.. attribute:: Cursor.rowcount
523
524 Although the :class:`Cursor` class of the :mod:`sqlite3` module implements this
525 attribute, the database engine's own support for the determination of "rows
526 affected"/"rows selected" is quirky.
527
Georg Brandl8ec7f652007-08-15 14:28:01 +0000528 For ``DELETE`` statements, SQLite reports :attr:`rowcount` as 0 if you make a
529 ``DELETE FROM table`` without any condition.
530
531 For :meth:`executemany` statements, the number of modifications are summed up
532 into :attr:`rowcount`.
533
534 As required by the Python DB API Spec, the :attr:`rowcount` attribute "is -1 in
Georg Brandl26497d92008-10-08 17:20:20 +0000535 case no ``executeXX()`` has been performed on the cursor or the rowcount of the
536 last operation is not determinable by the interface".
Georg Brandl8ec7f652007-08-15 14:28:01 +0000537
Georg Brandl891f1d32007-08-23 20:40:01 +0000538 This includes ``SELECT`` statements because we cannot determine the number of
539 rows a query produced until all rows were fetched.
540
Gerhard Häringc15317e2008-03-29 19:11:52 +0000541.. attribute:: Cursor.lastrowid
542
543 This read-only attribute provides the rowid of the last modified row. It is
544 only set if you issued a ``INSERT`` statement using the :meth:`execute`
545 method. For operations other than ``INSERT`` or when :meth:`executemany` is
546 called, :attr:`lastrowid` is set to :const:`None`.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000547
Georg Brandl26497d92008-10-08 17:20:20 +0000548.. attribute:: Cursor.description
549
550 This read-only attribute provides the column names of the last query. To
551 remain compatible with the Python DB API, it returns a 7-tuple for each
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000552 column where the last six items of each tuple are :const:`None`.
553
Georg Brandl26497d92008-10-08 17:20:20 +0000554 It is set for ``SELECT`` statements without any matching rows as well.
555
556.. _sqlite3-row-objects:
557
558Row Objects
559-----------
560
561.. class:: Row
562
563 A :class:`Row` instance serves as a highly optimized
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000564 :attr:`~Connection.row_factory` for :class:`Connection` objects.
Georg Brandl26497d92008-10-08 17:20:20 +0000565 It tries to mimic a tuple in most of its features.
566
567 It supports mapping access by column name and index, iteration,
568 representation, equality testing and :func:`len`.
569
570 If two :class:`Row` objects have exactly the same columns and their
571 members are equal, they compare equal.
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000572
Georg Brandl26497d92008-10-08 17:20:20 +0000573 .. versionchanged:: 2.6
574 Added iteration and equality (hashability).
575
576 .. method:: keys
577
578 This method returns a tuple of column names. Immediately after a query,
579 it is the first member of each tuple in :attr:`Cursor.description`.
580
581 .. versionadded:: 2.6
582
583Let's assume we initialize a table as in the example given above::
584
585 conn = sqlite3.connect(":memory:")
586 c = conn.cursor()
587 c.execute('''create table stocks
588 (date text, trans text, symbol text,
589 qty real, price real)''')
590 c.execute("""insert into stocks
591 values ('2006-01-05','BUY','RHAT',100,35.14)""")
592 conn.commit()
593 c.close()
594
595Now we plug :class:`Row` in::
596
597 >>> conn.row_factory = sqlite3.Row
598 >>> c = conn.cursor()
599 >>> c.execute('select * from stocks')
600 <sqlite3.Cursor object at 0x7f4e7dd8fa80>
601 >>> r = c.fetchone()
602 >>> type(r)
603 <type 'sqlite3.Row'>
604 >>> r
Mark Dickinson6b87f112009-11-24 14:27:02 +0000605 (u'2006-01-05', u'BUY', u'RHAT', 100.0, 35.14)
Georg Brandl26497d92008-10-08 17:20:20 +0000606 >>> len(r)
607 5
608 >>> r[2]
609 u'RHAT'
610 >>> r.keys()
611 ['date', 'trans', 'symbol', 'qty', 'price']
612 >>> r['qty']
613 100.0
614 >>> for member in r: print member
615 ...
616 2006-01-05
617 BUY
618 RHAT
619 100.0
620 35.14
621
622
Georg Brandl8ec7f652007-08-15 14:28:01 +0000623.. _sqlite3-types:
624
625SQLite and Python types
626-----------------------
627
628
629Introduction
630^^^^^^^^^^^^
631
Georg Brandl26497d92008-10-08 17:20:20 +0000632SQLite natively supports the following types: ``NULL``, ``INTEGER``,
633``REAL``, ``TEXT``, ``BLOB``.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000634
635The following Python types can thus be sent to SQLite without any problem:
636
Georg Brandl26497d92008-10-08 17:20:20 +0000637+-----------------------------+-------------+
638| Python type | SQLite type |
639+=============================+=============+
640| :const:`None` | ``NULL`` |
641+-----------------------------+-------------+
642| :class:`int` | ``INTEGER`` |
643+-----------------------------+-------------+
644| :class:`long` | ``INTEGER`` |
645+-----------------------------+-------------+
646| :class:`float` | ``REAL`` |
647+-----------------------------+-------------+
648| :class:`str` (UTF8-encoded) | ``TEXT`` |
649+-----------------------------+-------------+
650| :class:`unicode` | ``TEXT`` |
651+-----------------------------+-------------+
652| :class:`buffer` | ``BLOB`` |
653+-----------------------------+-------------+
Georg Brandl8ec7f652007-08-15 14:28:01 +0000654
655This is how SQLite types are converted to Python types by default:
656
Georg Brandl26497d92008-10-08 17:20:20 +0000657+-------------+----------------------------------------------+
658| SQLite type | Python type |
659+=============+==============================================+
660| ``NULL`` | :const:`None` |
661+-------------+----------------------------------------------+
662| ``INTEGER`` | :class:`int` or :class:`long`, |
663| | depending on size |
664+-------------+----------------------------------------------+
665| ``REAL`` | :class:`float` |
666+-------------+----------------------------------------------+
667| ``TEXT`` | depends on :attr:`~Connection.text_factory`, |
668| | :class:`unicode` by default |
669+-------------+----------------------------------------------+
670| ``BLOB`` | :class:`buffer` |
671+-------------+----------------------------------------------+
Georg Brandl8ec7f652007-08-15 14:28:01 +0000672
673The type system of the :mod:`sqlite3` module is extensible in two ways: you can
674store additional Python types in a SQLite database via object adaptation, and
675you can let the :mod:`sqlite3` module convert SQLite types to different Python
676types via converters.
677
678
679Using adapters to store additional Python types in SQLite databases
680^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
681
682As described before, SQLite supports only a limited set of types natively. To
683use other Python types with SQLite, you must **adapt** them to one of the
684sqlite3 module's supported types for SQLite: one of NoneType, int, long, float,
685str, unicode, buffer.
686
687The :mod:`sqlite3` module uses Python object adaptation, as described in
688:pep:`246` for this. The protocol to use is :class:`PrepareProtocol`.
689
690There are two ways to enable the :mod:`sqlite3` module to adapt a custom Python
691type to one of the supported ones.
692
693
694Letting your object adapt itself
695""""""""""""""""""""""""""""""""
696
697This is a good approach if you write the class yourself. Let's suppose you have
698a class like this::
699
700 class Point(object):
701 def __init__(self, x, y):
702 self.x, self.y = x, y
703
704Now you want to store the point in a single SQLite column. First you'll have to
705choose one of the supported types first to be used for representing the point.
706Let's just use str and separate the coordinates using a semicolon. Then you need
707to give your class a method ``__conform__(self, protocol)`` which must return
708the converted value. The parameter *protocol* will be :class:`PrepareProtocol`.
709
710.. literalinclude:: ../includes/sqlite3/adapter_point_1.py
711
712
713Registering an adapter callable
714"""""""""""""""""""""""""""""""
715
716The other possibility is to create a function that converts the type to the
717string representation and register the function with :meth:`register_adapter`.
718
719.. note::
720
Georg Brandla7395032007-10-21 12:15:05 +0000721 The type/class to adapt must be a :term:`new-style class`, i. e. it must have
Georg Brandl8ec7f652007-08-15 14:28:01 +0000722 :class:`object` as one of its bases.
723
724.. literalinclude:: ../includes/sqlite3/adapter_point_2.py
725
726The :mod:`sqlite3` module has two default adapters for Python's built-in
727:class:`datetime.date` and :class:`datetime.datetime` types. Now let's suppose
728we want to store :class:`datetime.datetime` objects not in ISO representation,
729but as a Unix timestamp.
730
731.. literalinclude:: ../includes/sqlite3/adapter_datetime.py
732
733
734Converting SQLite values to custom Python types
735^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
736
737Writing an adapter lets you send custom Python types to SQLite. But to make it
738really useful we need to make the Python to SQLite to Python roundtrip work.
739
740Enter converters.
741
742Let's go back to the :class:`Point` class. We stored the x and y coordinates
743separated via semicolons as strings in SQLite.
744
745First, we'll define a converter function that accepts the string as a parameter
746and constructs a :class:`Point` object from it.
747
748.. note::
749
750 Converter functions **always** get called with a string, no matter under which
751 data type you sent the value to SQLite.
752
Georg Brandl8ec7f652007-08-15 14:28:01 +0000753::
754
755 def convert_point(s):
756 x, y = map(float, s.split(";"))
757 return Point(x, y)
758
759Now you need to make the :mod:`sqlite3` module know that what you select from
760the database is actually a point. There are two ways of doing this:
761
762* Implicitly via the declared type
763
764* Explicitly via the column name
765
766Both ways are described in section :ref:`sqlite3-module-contents`, in the entries
767for the constants :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`.
768
769The following example illustrates both approaches.
770
771.. literalinclude:: ../includes/sqlite3/converter_point.py
772
773
774Default adapters and converters
775^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
776
777There are default adapters for the date and datetime types in the datetime
778module. They will be sent as ISO dates/ISO timestamps to SQLite.
779
780The default converters are registered under the name "date" for
781:class:`datetime.date` and under the name "timestamp" for
782:class:`datetime.datetime`.
783
784This way, you can use date/timestamps from Python without any additional
785fiddling in most cases. The format of the adapters is also compatible with the
786experimental SQLite date/time functions.
787
788The following example demonstrates this.
789
790.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py
791
792
793.. _sqlite3-controlling-transactions:
794
795Controlling Transactions
796------------------------
797
798By default, the :mod:`sqlite3` module opens transactions implicitly before a
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000799Data Modification Language (DML) statement (i.e.
Georg Brandl26497d92008-10-08 17:20:20 +0000800``INSERT``/``UPDATE``/``DELETE``/``REPLACE``), and commits transactions
801implicitly before a non-DML, non-query statement (i. e.
802anything other than ``SELECT`` or the aforementioned).
Georg Brandl8ec7f652007-08-15 14:28:01 +0000803
804So if you are within a transaction and issue a command like ``CREATE TABLE
805...``, ``VACUUM``, ``PRAGMA``, the :mod:`sqlite3` module will commit implicitly
806before executing that command. There are two reasons for doing that. The first
807is that some of these commands don't work within transactions. The other reason
Georg Brandl498a9b32009-05-20 18:31:14 +0000808is that sqlite3 needs to keep track of the transaction state (if a transaction
Georg Brandl8ec7f652007-08-15 14:28:01 +0000809is active or not).
810
Georg Brandl498a9b32009-05-20 18:31:14 +0000811You can control which kind of ``BEGIN`` statements sqlite3 implicitly executes
Georg Brandl8ec7f652007-08-15 14:28:01 +0000812(or none at all) via the *isolation_level* parameter to the :func:`connect`
813call, or via the :attr:`isolation_level` property of connections.
814
815If you want **autocommit mode**, then set :attr:`isolation_level` to None.
816
817Otherwise leave it at its default, which will result in a plain "BEGIN"
Georg Brandlb9bfea72008-11-06 10:19:11 +0000818statement, or set it to one of SQLite's supported isolation levels: "DEFERRED",
819"IMMEDIATE" or "EXCLUSIVE".
Georg Brandl8ec7f652007-08-15 14:28:01 +0000820
Georg Brandl8ec7f652007-08-15 14:28:01 +0000821
822
Georg Brandl498a9b32009-05-20 18:31:14 +0000823Using :mod:`sqlite3` efficiently
824--------------------------------
Georg Brandl8ec7f652007-08-15 14:28:01 +0000825
826
827Using shortcut methods
828^^^^^^^^^^^^^^^^^^^^^^
829
830Using the nonstandard :meth:`execute`, :meth:`executemany` and
831:meth:`executescript` methods of the :class:`Connection` object, your code can
832be written more concisely because you don't have to create the (often
833superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
834objects are created implicitly and these shortcut methods return the cursor
Georg Brandl26497d92008-10-08 17:20:20 +0000835objects. This way, you can execute a ``SELECT`` statement and iterate over it
Georg Brandl8ec7f652007-08-15 14:28:01 +0000836directly using only a single call on the :class:`Connection` object.
837
838.. literalinclude:: ../includes/sqlite3/shortcut_methods.py
839
840
841Accessing columns by name instead of by index
842^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
843
Georg Brandld7d4fd72009-07-26 14:37:28 +0000844One useful feature of the :mod:`sqlite3` module is the built-in
Georg Brandl8ec7f652007-08-15 14:28:01 +0000845:class:`sqlite3.Row` class designed to be used as a row factory.
846
847Rows wrapped with this class can be accessed both by index (like tuples) and
848case-insensitively by name:
849
850.. literalinclude:: ../includes/sqlite3/rowclass.py
851
Gerhard Häring41309302008-03-29 01:27:37 +0000852
853Using the connection as a context manager
854^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
855
856.. versionadded:: 2.6
857
858Connection objects can be used as context managers
859that automatically commit or rollback transactions. In the event of an
860exception, the transaction is rolled back; otherwise, the transaction is
861committed:
862
863.. literalinclude:: ../includes/sqlite3/ctx_manager.py