blob: 8ffbce39ef4a7eb4cc49460182bc9b85bb28e981 [file] [log] [blame]
Georg Brandl116aa622007-08-15 14:28:22 +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
Georg Brandl116aa622007-08-15 14:28:22 +00009SQLite is a C library that provides a lightweight disk-based database that
10doesn't require a separate server process and allows accessing the database
11using a nonstandard variant of the SQL query language. Some applications can use
12SQLite for internal data storage. It's also possible to prototype an
13application using SQLite and then port the code to a larger database such as
14PostgreSQL or Oracle.
15
16pysqlite was written by Gerhard Häring and provides a SQL interface compliant
17with the DB-API 2.0 specification described by :pep:`249`.
18
19To use the module, you must first create a :class:`Connection` object that
20represents the database. Here the data will be stored in the
21:file:`/tmp/example` file::
22
23 conn = sqlite3.connect('/tmp/example')
24
25You can also supply the special name ``:memory:`` to create a database in RAM.
26
27Once you have a :class:`Connection`, you can create a :class:`Cursor` object
Benjamin Petersonf10a79a2008-10-11 00:49:57 +000028and call its :meth:`~Cursor.execute` method to perform SQL commands::
Georg Brandl116aa622007-08-15 14:28:22 +000029
30 c = conn.cursor()
31
32 # Create table
33 c.execute('''create table stocks
34 (date text, trans text, symbol text,
35 qty real, price real)''')
36
37 # Insert a row of data
38 c.execute("""insert into stocks
39 values ('2006-01-05','BUY','RHAT',100,35.14)""")
40
41 # Save (commit) the changes
42 conn.commit()
43
44 # We can also close the cursor if we are done with it
45 c.close()
46
47Usually your SQL operations will need to use values from Python variables. You
48shouldn't assemble your query using Python's string operations because doing so
49is insecure; it makes your program vulnerable to an SQL injection attack.
50
51Instead, use the DB-API's parameter substitution. Put ``?`` as a placeholder
52wherever you want to use a value, and then provide a tuple of values as the
Benjamin Petersonf10a79a2008-10-11 00:49:57 +000053second argument to the cursor's :meth:`~Cursor.execute` method. (Other database modules
Georg Brandl116aa622007-08-15 14:28:22 +000054may use a different placeholder, such as ``%s`` or ``:1``.) For example::
55
56 # Never do this -- insecure!
57 symbol = 'IBM'
58 c.execute("... where symbol = '%s'" % symbol)
59
60 # Do this instead
61 t = (symbol,)
62 c.execute('select * from stocks where symbol=?', t)
63
64 # Larger example
65 for t in (('2006-03-28', 'BUY', 'IBM', 1000, 45.00),
66 ('2006-04-05', 'BUY', 'MSOFT', 1000, 72.00),
67 ('2006-04-06', 'SELL', 'IBM', 500, 53.00),
68 ):
69 c.execute('insert into stocks values (?,?,?,?,?)', t)
70
Georg Brandl9afde1c2007-11-01 20:32:30 +000071To retrieve data after executing a SELECT statement, you can either treat the
Benjamin Petersonf10a79a2008-10-11 00:49:57 +000072cursor as an :term:`iterator`, call the cursor's :meth:`~Cursor.fetchone` method to
73retrieve a single matching row, or call :meth:`~Cursor.fetchall` to get a list of the
Georg Brandl9afde1c2007-11-01 20:32:30 +000074matching rows.
Georg Brandl116aa622007-08-15 14:28:22 +000075
76This example uses the iterator form::
77
78 >>> c = conn.cursor()
79 >>> c.execute('select * from stocks order by price')
80 >>> for row in c:
Georg Brandl6911e3c2007-09-04 07:15:32 +000081 ... print(row)
Georg Brandl116aa622007-08-15 14:28:22 +000082 ...
83 (u'2006-01-05', u'BUY', u'RHAT', 100, 35.140000000000001)
84 (u'2006-03-28', u'BUY', u'IBM', 1000, 45.0)
85 (u'2006-04-06', u'SELL', u'IBM', 500, 53.0)
86 (u'2006-04-05', u'BUY', u'MSOFT', 1000, 72.0)
87 >>>
88
89
90.. seealso::
91
92 http://www.pysqlite.org
93 The pysqlite web page.
94
95 http://www.sqlite.org
96 The SQLite web page; the documentation describes the syntax and the available
97 data types for the supported SQL dialect.
98
99 :pep:`249` - Database API Specification 2.0
100 PEP written by Marc-André Lemburg.
101
102
103.. _sqlite3-module-contents:
104
105Module functions and constants
106------------------------------
107
108
109.. data:: PARSE_DECLTYPES
110
111 This constant is meant to be used with the *detect_types* parameter of the
112 :func:`connect` function.
113
114 Setting it makes the :mod:`sqlite3` module parse the declared type for each
Christian Heimes81ee3ef2008-05-04 22:42:01 +0000115 column it returns. It will parse out the first word of the declared type,
116 i. e. for "integer primary key", it will parse out "integer", or for
117 "number(10)" it will parse out "number". Then for that column, it will look
118 into the converters dictionary and use the converter function registered for
119 that type there.
Georg Brandl116aa622007-08-15 14:28:22 +0000120
121
122.. data:: PARSE_COLNAMES
123
124 This constant is meant to be used with the *detect_types* parameter of the
125 :func:`connect` function.
126
127 Setting this makes the SQLite interface parse the column name for each column it
128 returns. It will look for a string formed [mytype] in there, and then decide
129 that 'mytype' is the type of the column. It will try to find an entry of
130 'mytype' in the converters dictionary and then use the converter function found
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000131 there to return the value. The column name found in :attr:`Cursor.description`
Georg Brandl116aa622007-08-15 14:28:22 +0000132 is only the first word of the column name, i. e. if you use something like
133 ``'as "x [datetime]"'`` in your SQL, then we will parse out everything until the
134 first blank for the column name: the column name would simply be "x".
135
136
137.. function:: connect(database[, timeout, isolation_level, detect_types, factory])
138
139 Opens a connection to the SQLite database file *database*. You can use
140 ``":memory:"`` to open a database connection to a database that resides in RAM
141 instead of on disk.
142
143 When a database is accessed by multiple connections, and one of the processes
144 modifies the database, the SQLite database is locked until that transaction is
145 committed. The *timeout* parameter specifies how long the connection should wait
146 for the lock to go away until raising an exception. The default for the timeout
147 parameter is 5.0 (five seconds).
148
149 For the *isolation_level* parameter, please see the
150 :attr:`Connection.isolation_level` property of :class:`Connection` objects.
151
152 SQLite natively supports only the types TEXT, INTEGER, FLOAT, BLOB and NULL. If
153 you want to use other types you must add support for them yourself. The
154 *detect_types* parameter and the using custom **converters** registered with the
155 module-level :func:`register_converter` function allow you to easily do that.
156
157 *detect_types* defaults to 0 (i. e. off, no type detection), you can set it to
158 any combination of :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES` to turn
159 type detection on.
160
161 By default, the :mod:`sqlite3` module uses its :class:`Connection` class for the
162 connect call. You can, however, subclass the :class:`Connection` class and make
163 :func:`connect` use your class instead by providing your class for the *factory*
164 parameter.
165
166 Consult the section :ref:`sqlite3-types` of this manual for details.
167
168 The :mod:`sqlite3` module internally uses a statement cache to avoid SQL parsing
169 overhead. If you want to explicitly set the number of statements that are cached
170 for the connection, you can set the *cached_statements* parameter. The currently
171 implemented default is to cache 100 statements.
172
173
174.. function:: register_converter(typename, callable)
175
176 Registers a callable to convert a bytestring from the database into a custom
177 Python type. The callable will be invoked for all database values that are of
178 the type *typename*. Confer the parameter *detect_types* of the :func:`connect`
179 function for how the type detection works. Note that the case of *typename* and
180 the name of the type in your query must match!
181
182
183.. function:: register_adapter(type, callable)
184
185 Registers a callable to convert the custom Python type *type* into one of
186 SQLite's supported types. The callable *callable* accepts as single parameter
Georg Brandl5c106642007-11-29 17:41:05 +0000187 the Python value, and must return a value of the following types: int,
Georg Brandlf6945182008-02-01 11:56:49 +0000188 float, str, bytes (UTF-8 encoded) or buffer.
Georg Brandl116aa622007-08-15 14:28:22 +0000189
190
191.. function:: complete_statement(sql)
192
193 Returns :const:`True` if the string *sql* contains one or more complete SQL
194 statements terminated by semicolons. It does not verify that the SQL is
195 syntactically correct, only that there are no unclosed string literals and the
196 statement is terminated by a semicolon.
197
198 This can be used to build a shell for SQLite, as in the following example:
199
200
201 .. literalinclude:: ../includes/sqlite3/complete_statement.py
202
203
204.. function:: enable_callback_tracebacks(flag)
205
206 By default you will not get any tracebacks in user-defined functions,
207 aggregates, converters, authorizer callbacks etc. If you want to debug them, you
208 can call this function with *flag* as True. Afterwards, you will get tracebacks
209 from callbacks on ``sys.stderr``. Use :const:`False` to disable the feature
210 again.
211
212
213.. _sqlite3-connection-objects:
214
215Connection Objects
216------------------
217
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000218.. class:: Connection
219
220 A SQLite database connection has the following attributes and methods:
Georg Brandl116aa622007-08-15 14:28:22 +0000221
222.. attribute:: Connection.isolation_level
223
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000224 Get or set the current isolation level. :const:`None` for autocommit mode or one of
Georg Brandl116aa622007-08-15 14:28:22 +0000225 "DEFERRED", "IMMEDIATE" or "EXLUSIVE". See section
226 :ref:`sqlite3-controlling-transactions` for a more detailed explanation.
227
228
229.. method:: Connection.cursor([cursorClass])
230
231 The cursor method accepts a single optional parameter *cursorClass*. If
232 supplied, this must be a custom cursor class that extends
233 :class:`sqlite3.Cursor`.
234
235
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000236.. method:: Connection.commit()
237
238 This method commits the current transaction. If you don't call this method,
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000239 anything you did since the last call to ``commit()`` is not visible from from
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000240 other database connections. If you wonder why you don't see the data you've
241 written to the database, please check you didn't forget to call this method.
242
243.. method:: Connection.rollback()
244
245 This method rolls back any changes to the database since the last call to
246 :meth:`commit`.
247
248.. method:: Connection.close()
249
250 This closes the database connection. Note that this does not automatically
251 call :meth:`commit`. If you just close your database connection without
252 calling :meth:`commit` first, your changes will be lost!
253
Georg Brandl116aa622007-08-15 14:28:22 +0000254.. method:: Connection.execute(sql, [parameters])
255
256 This is a nonstandard shortcut that creates an intermediate cursor object by
257 calling the cursor method, then calls the cursor's :meth:`execute` method with
258 the parameters given.
259
260
261.. method:: Connection.executemany(sql, [parameters])
262
263 This is a nonstandard shortcut that creates an intermediate cursor object by
264 calling the cursor method, then calls the cursor's :meth:`executemany` method
265 with the parameters given.
266
267
268.. method:: Connection.executescript(sql_script)
269
270 This is a nonstandard shortcut that creates an intermediate cursor object by
271 calling the cursor method, then calls the cursor's :meth:`executescript` method
272 with the parameters given.
273
274
275.. method:: Connection.create_function(name, num_params, func)
276
277 Creates a user-defined function that you can later use from within SQL
278 statements under the function name *name*. *num_params* is the number of
279 parameters the function accepts, and *func* is a Python callable that is called
280 as the SQL function.
281
Georg Brandlf6945182008-02-01 11:56:49 +0000282 The function can return any of the types supported by SQLite: bytes, str, int,
Georg Brandl5c106642007-11-29 17:41:05 +0000283 float, buffer and None.
Georg Brandl116aa622007-08-15 14:28:22 +0000284
285 Example:
286
287 .. literalinclude:: ../includes/sqlite3/md5func.py
288
289
290.. method:: Connection.create_aggregate(name, num_params, aggregate_class)
291
292 Creates a user-defined aggregate function.
293
294 The aggregate class must implement a ``step`` method, which accepts the number
295 of parameters *num_params*, and a ``finalize`` method which will return the
296 final result of the aggregate.
297
298 The ``finalize`` method can return any of the types supported by SQLite:
Georg Brandlf6945182008-02-01 11:56:49 +0000299 bytes, str, int, float, buffer and None.
Georg Brandl116aa622007-08-15 14:28:22 +0000300
301 Example:
302
303 .. literalinclude:: ../includes/sqlite3/mysumaggr.py
304
305
306.. method:: Connection.create_collation(name, callable)
307
308 Creates a collation with the specified *name* and *callable*. The callable will
309 be passed two string arguments. It should return -1 if the first is ordered
310 lower than the second, 0 if they are ordered equal and 1 if the first is ordered
311 higher than the second. Note that this controls sorting (ORDER BY in SQL) so
312 your comparisons don't affect other SQL operations.
313
314 Note that the callable will get its parameters as Python bytestrings, which will
315 normally be encoded in UTF-8.
316
317 The following example shows a custom collation that sorts "the wrong way":
318
319 .. literalinclude:: ../includes/sqlite3/collation_reverse.py
320
321 To remove a collation, call ``create_collation`` with None as callable::
322
323 con.create_collation("reverse", None)
324
325
326.. method:: Connection.interrupt()
327
328 You can call this method from a different thread to abort any queries that might
329 be executing on the connection. The query will then abort and the caller will
330 get an exception.
331
332
333.. method:: Connection.set_authorizer(authorizer_callback)
334
335 This routine registers a callback. The callback is invoked for each attempt to
336 access a column of a table in the database. The callback should return
337 :const:`SQLITE_OK` if access is allowed, :const:`SQLITE_DENY` if the entire SQL
338 statement should be aborted with an error and :const:`SQLITE_IGNORE` if the
339 column should be treated as a NULL value. These constants are available in the
340 :mod:`sqlite3` module.
341
342 The first argument to the callback signifies what kind of operation is to be
343 authorized. The second and third argument will be arguments or :const:`None`
344 depending on the first argument. The 4th argument is the name of the database
345 ("main", "temp", etc.) if applicable. The 5th argument is the name of the
346 inner-most trigger or view that is responsible for the access attempt or
347 :const:`None` if this access attempt is directly from input SQL code.
348
349 Please consult the SQLite documentation about the possible values for the first
350 argument and the meaning of the second and third argument depending on the first
351 one. All necessary constants are available in the :mod:`sqlite3` module.
352
353
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000354.. method:: Connection.set_progress_handler(handler, n)
355
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000356 This routine registers a callback. The callback is invoked for every *n*
357 instructions of the SQLite virtual machine. This is useful if you want to
358 get called from SQLite during long-running operations, for example to update
359 a GUI.
360
361 If you want to clear any previously installed progress handler, call the
362 method with :const:`None` for *handler*.
363
364
Georg Brandl116aa622007-08-15 14:28:22 +0000365.. attribute:: Connection.row_factory
366
367 You can change this attribute to a callable that accepts the cursor and the
368 original row as a tuple and will return the real result row. This way, you can
369 implement more advanced ways of returning results, such as returning an object
370 that can also access columns by name.
371
372 Example:
373
374 .. literalinclude:: ../includes/sqlite3/row_factory.py
375
376 If returning a tuple doesn't suffice and you want name-based access to
377 columns, you should consider setting :attr:`row_factory` to the
378 highly-optimized :class:`sqlite3.Row` type. :class:`Row` provides both
379 index-based and case-insensitive name-based access to columns with almost no
380 memory overhead. It will probably be better than your own custom
381 dictionary-based approach or even a db_row based solution.
382
Christian Heimes5b5e81c2007-12-31 16:14:33 +0000383 .. XXX what's a db_row-based solution?
Georg Brandl116aa622007-08-15 14:28:22 +0000384
385
386.. attribute:: Connection.text_factory
387
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000388 Using this attribute you can control what objects are returned for the ``TEXT``
389 data type. By default, this attribute is set to :class:`str` and the
390 :mod:`sqlite3` module will return Unicode objects for ``TEXT``. If you want to
Georg Brandlf6945182008-02-01 11:56:49 +0000391 return bytestrings instead, you can set it to :class:`bytes`.
Georg Brandl116aa622007-08-15 14:28:22 +0000392
Georg Brandlf6945182008-02-01 11:56:49 +0000393 For efficiency reasons, there's also a way to return :class:`str` objects
394 only for non-ASCII data, and :class:`bytes` otherwise. To activate it, set
395 this attribute to :const:`sqlite3.OptimizedUnicode`.
Georg Brandl116aa622007-08-15 14:28:22 +0000396
397 You can also set it to any other callable that accepts a single bytestring
398 parameter and returns the resulting object.
399
400 See the following example code for illustration:
401
402 .. literalinclude:: ../includes/sqlite3/text_factory.py
403
404
405.. attribute:: Connection.total_changes
406
407 Returns the total number of database rows that have been modified, inserted, or
408 deleted since the database connection was opened.
409
410
Christian Heimesbbe741d2008-03-28 10:53:29 +0000411.. attribute:: Connection.iterdump
412
413 Returns an iterator to dump the database in an SQL text format. Useful when
414 saving an in-memory database for later restoration. This function provides
415 the same capabilities as the :kbd:`.dump` command in the :program:`sqlite3`
416 shell.
417
Christian Heimesbbe741d2008-03-28 10:53:29 +0000418 Example::
419
420 # Convert file existing_db.db to SQL dump file dump.sql
421 import sqlite3, os
422
423 con = sqlite3.connect('existing_db.db')
Benjamin Petersonae5360b2008-09-08 23:05:23 +0000424 full_dump = os.linesep.join(con.iterdump())
Christian Heimesbbe741d2008-03-28 10:53:29 +0000425 f = open('dump.sql', 'w')
426 f.writelines(full_dump)
427 f.close()
428
429
Georg Brandl116aa622007-08-15 14:28:22 +0000430.. _sqlite3-cursor-objects:
431
432Cursor Objects
433--------------
434
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000435.. class:: Cursor
Georg Brandl116aa622007-08-15 14:28:22 +0000436
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000437 A SQLite database cursor has the following attributes and methods:
Georg Brandl116aa622007-08-15 14:28:22 +0000438
439.. method:: Cursor.execute(sql, [parameters])
440
Christian Heimesfdab48e2008-01-20 09:06:41 +0000441 Executes an SQL statement. The SQL statement may be parametrized (i. e.
Georg Brandl116aa622007-08-15 14:28:22 +0000442 placeholders instead of SQL literals). The :mod:`sqlite3` module supports two
443 kinds of placeholders: question marks (qmark style) and named placeholders
444 (named style).
445
446 This example shows how to use parameters with qmark style:
447
448 .. literalinclude:: ../includes/sqlite3/execute_1.py
449
450 This example shows how to use the named style:
451
452 .. literalinclude:: ../includes/sqlite3/execute_2.py
453
454 :meth:`execute` will only execute a single SQL statement. If you try to execute
455 more than one statement with it, it will raise a Warning. Use
456 :meth:`executescript` if you want to execute multiple SQL statements with one
457 call.
458
459
460.. method:: Cursor.executemany(sql, seq_of_parameters)
461
Christian Heimesfdab48e2008-01-20 09:06:41 +0000462 Executes an SQL command against all parameter sequences or mappings found in
Georg Brandl9afde1c2007-11-01 20:32:30 +0000463 the sequence *sql*. The :mod:`sqlite3` module also allows using an
464 :term:`iterator` yielding parameters instead of a sequence.
Georg Brandl116aa622007-08-15 14:28:22 +0000465
466 .. literalinclude:: ../includes/sqlite3/executemany_1.py
467
Georg Brandl9afde1c2007-11-01 20:32:30 +0000468 Here's a shorter example using a :term:`generator`:
Georg Brandl116aa622007-08-15 14:28:22 +0000469
470 .. literalinclude:: ../includes/sqlite3/executemany_2.py
471
472
473.. method:: Cursor.executescript(sql_script)
474
475 This is a nonstandard convenience method for executing multiple SQL statements
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000476 at once. It issues a ``COMMIT`` statement first, then executes the SQL script it
Georg Brandl116aa622007-08-15 14:28:22 +0000477 gets as a parameter.
478
Georg Brandlf6945182008-02-01 11:56:49 +0000479 *sql_script* can be an instance of :class:`str` or :class:`bytes`.
Georg Brandl116aa622007-08-15 14:28:22 +0000480
481 Example:
482
483 .. literalinclude:: ../includes/sqlite3/executescript.py
484
485
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000486.. method:: Cursor.fetchone()
487
Christian Heimesfdab48e2008-01-20 09:06:41 +0000488 Fetches the next row of a query result set, returning a single sequence,
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000489 or :const:`None` when no more data is available.
Christian Heimesfdab48e2008-01-20 09:06:41 +0000490
491
492.. method:: Cursor.fetchmany([size=cursor.arraysize])
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000493
Christian Heimesfdab48e2008-01-20 09:06:41 +0000494 Fetches the next set of rows of a query result, returning a list. An empty
495 list is returned when no more rows are available.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000496
Christian Heimesfdab48e2008-01-20 09:06:41 +0000497 The number of rows to fetch per call is specified by the *size* parameter.
498 If it is not given, the cursor's arraysize determines the number of rows
499 to be fetched. The method should try to fetch as many rows as indicated by
500 the size parameter. If this is not possible due to the specified number of
501 rows not being available, fewer rows may be returned.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000502
Christian Heimesfdab48e2008-01-20 09:06:41 +0000503 Note there are performance considerations involved with the *size* parameter.
504 For optimal performance, it is usually best to use the arraysize attribute.
505 If the *size* parameter is used, then it is best for it to retain the same
506 value from one :meth:`fetchmany` call to the next.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000507
508.. method:: Cursor.fetchall()
Christian Heimesfdab48e2008-01-20 09:06:41 +0000509
510 Fetches all (remaining) rows of a query result, returning a list. Note that
511 the cursor's arraysize attribute can affect the performance of this operation.
512 An empty list is returned when no rows are available.
513
514
Georg Brandl116aa622007-08-15 14:28:22 +0000515.. attribute:: Cursor.rowcount
516
517 Although the :class:`Cursor` class of the :mod:`sqlite3` module implements this
518 attribute, the database engine's own support for the determination of "rows
519 affected"/"rows selected" is quirky.
520
Georg Brandl116aa622007-08-15 14:28:22 +0000521 For ``DELETE`` statements, SQLite reports :attr:`rowcount` as 0 if you make a
522 ``DELETE FROM table`` without any condition.
523
524 For :meth:`executemany` statements, the number of modifications are summed up
525 into :attr:`rowcount`.
526
527 As required by the Python DB API Spec, the :attr:`rowcount` attribute "is -1 in
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000528 case no ``executeXX()`` has been performed on the cursor or the rowcount of the
529 last operation is not determinable by the interface".
Georg Brandl116aa622007-08-15 14:28:22 +0000530
Guido van Rossum04110fb2007-08-24 16:32:05 +0000531 This includes ``SELECT`` statements because we cannot determine the number of
532 rows a query produced until all rows were fetched.
533
Gerhard Häringd3372792008-03-29 19:13:55 +0000534.. attribute:: Cursor.lastrowid
535
536 This read-only attribute provides the rowid of the last modified row. It is
537 only set if you issued a ``INSERT`` statement using the :meth:`execute`
538 method. For operations other than ``INSERT`` or when :meth:`executemany` is
539 called, :attr:`lastrowid` is set to :const:`None`.
Georg Brandl116aa622007-08-15 14:28:22 +0000540
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000541.. attribute:: Cursor.description
542
543 This read-only attribute provides the column names of the last query. To
544 remain compatible with the Python DB API, it returns a 7-tuple for each
545 column where the last six items of each tuple are :const:`None`.
546
547 It is set for ``SELECT`` statements without any matching rows as well.
548
549.. _sqlite3-row-objects:
550
551Row Objects
552-----------
553
554.. class:: Row
555
556 A :class:`Row` instance serves as a highly optimized
557 :attr:`~Connection.row_factory` for :class:`Connection` objects.
558 It tries to mimic a tuple in most of its features.
559
560 It supports mapping access by column name and index, iteration,
561 representation, equality testing and :func:`len`.
562
563 If two :class:`Row` objects have exactly the same columns and their
564 members are equal, they compare equal.
565
566 .. versionchanged:: 2.6
567 Added iteration and equality (hashability).
568
569 .. method:: keys
570
571 This method returns a tuple of column names. Immediately after a query,
572 it is the first member of each tuple in :attr:`Cursor.description`.
573
574 .. versionadded:: 2.6
575
576Let's assume we initialize a table as in the example given above::
577
578 conn = sqlite3.connect(":memory:")
579 c = conn.cursor()
580 c.execute('''create table stocks
581 (date text, trans text, symbol text,
582 qty real, price real)''')
583 c.execute("""insert into stocks
584 values ('2006-01-05','BUY','RHAT',100,35.14)""")
585 conn.commit()
586 c.close()
587
588Now we plug :class:`Row` in::
589
590 >>> conn.row_factory = sqlite3.Row
591 >>> c = conn.cursor()
592 >>> c.execute('select * from stocks')
593 <sqlite3.Cursor object at 0x7f4e7dd8fa80>
594 >>> r = c.fetchone()
595 >>> type(r)
596 <type 'sqlite3.Row'>
597 >>> r
598 (u'2006-01-05', u'BUY', u'RHAT', 100.0, 35.140000000000001)
599 >>> len(r)
600 5
601 >>> r[2]
602 u'RHAT'
603 >>> r.keys()
604 ['date', 'trans', 'symbol', 'qty', 'price']
605 >>> r['qty']
606 100.0
607 >>> for member in r: print member
608 ...
609 2006-01-05
610 BUY
611 RHAT
612 100.0
613 35.14
614
615
Georg Brandl116aa622007-08-15 14:28:22 +0000616.. _sqlite3-types:
617
618SQLite and Python types
619-----------------------
620
621
622Introduction
623^^^^^^^^^^^^
624
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000625SQLite natively supports the following types: ``NULL``, ``INTEGER``,
626``REAL``, ``TEXT``, ``BLOB``.
Georg Brandl116aa622007-08-15 14:28:22 +0000627
628The following Python types can thus be sent to SQLite without any problem:
629
Georg Brandlf6945182008-02-01 11:56:49 +0000630+-------------------------------+-------------+
631| Python type | SQLite type |
632+===============================+=============+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000633| :const:`None` | ``NULL`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000634+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000635| :class:`int` | ``INTEGER`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000636+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000637| :class:`float` | ``REAL`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000638+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000639| :class:`bytes` (UTF8-encoded) | ``TEXT`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000640+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000641| :class:`str` | ``TEXT`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000642+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000643| :class:`buffer` | ``BLOB`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000644+-------------------------------+-------------+
Georg Brandl116aa622007-08-15 14:28:22 +0000645
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000646
Georg Brandl116aa622007-08-15 14:28:22 +0000647This is how SQLite types are converted to Python types by default:
648
649+-------------+---------------------------------------------+
650| SQLite type | Python type |
651+=============+=============================================+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000652| ``NULL`` | :const:`None` |
Georg Brandl116aa622007-08-15 14:28:22 +0000653+-------------+---------------------------------------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000654| ``INTEGER`` | :class`int` |
Georg Brandl116aa622007-08-15 14:28:22 +0000655+-------------+---------------------------------------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000656| ``REAL`` | :class:`float` |
Georg Brandl116aa622007-08-15 14:28:22 +0000657+-------------+---------------------------------------------+
Georg Brandlf6945182008-02-01 11:56:49 +0000658| ``TEXT`` | depends on text_factory, str by default |
Georg Brandl116aa622007-08-15 14:28:22 +0000659+-------------+---------------------------------------------+
660| ``BLOB`` | buffer |
661+-------------+---------------------------------------------+
662
663The type system of the :mod:`sqlite3` module is extensible in two ways: you can
664store additional Python types in a SQLite database via object adaptation, and
665you can let the :mod:`sqlite3` module convert SQLite types to different Python
666types via converters.
667
668
669Using adapters to store additional Python types in SQLite databases
670^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
671
672As described before, SQLite supports only a limited set of types natively. To
673use other Python types with SQLite, you must **adapt** them to one of the
Georg Brandl5c106642007-11-29 17:41:05 +0000674sqlite3 module's supported types for SQLite: one of NoneType, int, float,
Georg Brandlf6945182008-02-01 11:56:49 +0000675str, bytes, buffer.
Georg Brandl116aa622007-08-15 14:28:22 +0000676
677The :mod:`sqlite3` module uses Python object adaptation, as described in
678:pep:`246` for this. The protocol to use is :class:`PrepareProtocol`.
679
680There are two ways to enable the :mod:`sqlite3` module to adapt a custom Python
681type to one of the supported ones.
682
683
684Letting your object adapt itself
685""""""""""""""""""""""""""""""""
686
687This is a good approach if you write the class yourself. Let's suppose you have
688a class like this::
689
690 class Point(object):
691 def __init__(self, x, y):
692 self.x, self.y = x, y
693
694Now you want to store the point in a single SQLite column. First you'll have to
695choose one of the supported types first to be used for representing the point.
696Let's just use str and separate the coordinates using a semicolon. Then you need
697to give your class a method ``__conform__(self, protocol)`` which must return
698the converted value. The parameter *protocol* will be :class:`PrepareProtocol`.
699
700.. literalinclude:: ../includes/sqlite3/adapter_point_1.py
701
702
703Registering an adapter callable
704"""""""""""""""""""""""""""""""
705
706The other possibility is to create a function that converts the type to the
707string representation and register the function with :meth:`register_adapter`.
708
Georg Brandl116aa622007-08-15 14:28:22 +0000709.. literalinclude:: ../includes/sqlite3/adapter_point_2.py
710
711The :mod:`sqlite3` module has two default adapters for Python's built-in
712:class:`datetime.date` and :class:`datetime.datetime` types. Now let's suppose
713we want to store :class:`datetime.datetime` objects not in ISO representation,
714but as a Unix timestamp.
715
716.. literalinclude:: ../includes/sqlite3/adapter_datetime.py
717
718
719Converting SQLite values to custom Python types
720^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
721
722Writing an adapter lets you send custom Python types to SQLite. But to make it
723really useful we need to make the Python to SQLite to Python roundtrip work.
724
725Enter converters.
726
727Let's go back to the :class:`Point` class. We stored the x and y coordinates
728separated via semicolons as strings in SQLite.
729
730First, we'll define a converter function that accepts the string as a parameter
731and constructs a :class:`Point` object from it.
732
733.. note::
734
735 Converter functions **always** get called with a string, no matter under which
736 data type you sent the value to SQLite.
737
Georg Brandl116aa622007-08-15 14:28:22 +0000738::
739
740 def convert_point(s):
741 x, y = map(float, s.split(";"))
742 return Point(x, y)
743
744Now you need to make the :mod:`sqlite3` module know that what you select from
745the database is actually a point. There are two ways of doing this:
746
747* Implicitly via the declared type
748
749* Explicitly via the column name
750
751Both ways are described in section :ref:`sqlite3-module-contents`, in the entries
752for the constants :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`.
753
754The following example illustrates both approaches.
755
756.. literalinclude:: ../includes/sqlite3/converter_point.py
757
758
759Default adapters and converters
760^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
761
762There are default adapters for the date and datetime types in the datetime
763module. They will be sent as ISO dates/ISO timestamps to SQLite.
764
765The default converters are registered under the name "date" for
766:class:`datetime.date` and under the name "timestamp" for
767:class:`datetime.datetime`.
768
769This way, you can use date/timestamps from Python without any additional
770fiddling in most cases. The format of the adapters is also compatible with the
771experimental SQLite date/time functions.
772
773The following example demonstrates this.
774
775.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py
776
777
778.. _sqlite3-controlling-transactions:
779
780Controlling Transactions
781------------------------
782
783By default, the :mod:`sqlite3` module opens transactions implicitly before a
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000784Data Modification Language (DML) statement (i.e.
785``INSERT``/``UPDATE``/``DELETE``/``REPLACE``), and commits transactions
786implicitly before a non-DML, non-query statement (i. e.
787anything other than ``SELECT`` or the aforementioned).
Georg Brandl116aa622007-08-15 14:28:22 +0000788
789So if you are within a transaction and issue a command like ``CREATE TABLE
790...``, ``VACUUM``, ``PRAGMA``, the :mod:`sqlite3` module will commit implicitly
791before executing that command. There are two reasons for doing that. The first
792is that some of these commands don't work within transactions. The other reason
793is that pysqlite needs to keep track of the transaction state (if a transaction
794is active or not).
795
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000796You can control which kind of ``BEGIN`` statements pysqlite implicitly executes
Georg Brandl116aa622007-08-15 14:28:22 +0000797(or none at all) via the *isolation_level* parameter to the :func:`connect`
798call, or via the :attr:`isolation_level` property of connections.
799
800If you want **autocommit mode**, then set :attr:`isolation_level` to None.
801
802Otherwise leave it at its default, which will result in a plain "BEGIN"
803statement, or set it to one of SQLite's supported isolation levels: DEFERRED,
804IMMEDIATE or EXCLUSIVE.
805
Georg Brandl116aa622007-08-15 14:28:22 +0000806
807
808Using pysqlite efficiently
809--------------------------
810
811
812Using shortcut methods
813^^^^^^^^^^^^^^^^^^^^^^
814
815Using the nonstandard :meth:`execute`, :meth:`executemany` and
816:meth:`executescript` methods of the :class:`Connection` object, your code can
817be written more concisely because you don't have to create the (often
818superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
819objects are created implicitly and these shortcut methods return the cursor
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000820objects. This way, you can execute a ``SELECT`` statement and iterate over it
Georg Brandl116aa622007-08-15 14:28:22 +0000821directly using only a single call on the :class:`Connection` object.
822
823.. literalinclude:: ../includes/sqlite3/shortcut_methods.py
824
825
826Accessing columns by name instead of by index
827^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
828
829One useful feature of the :mod:`sqlite3` module is the builtin
830:class:`sqlite3.Row` class designed to be used as a row factory.
831
832Rows wrapped with this class can be accessed both by index (like tuples) and
833case-insensitively by name:
834
835.. literalinclude:: ../includes/sqlite3/rowclass.py
836
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000837
838Using the connection as a context manager
839^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
840
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000841Connection objects can be used as context managers
842that automatically commit or rollback transactions. In the event of an
843exception, the transaction is rolled back; otherwise, the transaction is
844committed:
845
846.. literalinclude:: ../includes/sqlite3/ctx_manager.py