blob: bf9b186180b57d651c1ed9d82e5ee4a0f53ab455 [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
28and call its :meth:`execute` method to perform SQL commands::
29
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
53second argument to the cursor's :meth:`execute` method. (Other database modules
54may 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
72cursor as an :term:`iterator`, call the cursor's :meth:`fetchone` method to
73retrieve a single matching row, or call :meth:`fetchall` to get a list of the
74matching 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
115 column it returns. It will parse out the first word of the declared type, i. e.
116 for "integer primary key", it will parse out "integer". Then for that column, it
117 will look into the converters dictionary and use the converter function
118 registered for that type there. Converter names are case-sensitive!
119
120
121.. data:: PARSE_COLNAMES
122
123 This constant is meant to be used with the *detect_types* parameter of the
124 :func:`connect` function.
125
126 Setting this makes the SQLite interface parse the column name for each column it
127 returns. It will look for a string formed [mytype] in there, and then decide
128 that 'mytype' is the type of the column. It will try to find an entry of
129 'mytype' in the converters dictionary and then use the converter function found
130 there to return the value. The column name found in :attr:`cursor.description`
131 is only the first word of the column name, i. e. if you use something like
132 ``'as "x [datetime]"'`` in your SQL, then we will parse out everything until the
133 first blank for the column name: the column name would simply be "x".
134
135
136.. function:: connect(database[, timeout, isolation_level, detect_types, factory])
137
138 Opens a connection to the SQLite database file *database*. You can use
139 ``":memory:"`` to open a database connection to a database that resides in RAM
140 instead of on disk.
141
142 When a database is accessed by multiple connections, and one of the processes
143 modifies the database, the SQLite database is locked until that transaction is
144 committed. The *timeout* parameter specifies how long the connection should wait
145 for the lock to go away until raising an exception. The default for the timeout
146 parameter is 5.0 (five seconds).
147
148 For the *isolation_level* parameter, please see the
149 :attr:`Connection.isolation_level` property of :class:`Connection` objects.
150
151 SQLite natively supports only the types TEXT, INTEGER, FLOAT, BLOB and NULL. If
152 you want to use other types you must add support for them yourself. The
153 *detect_types* parameter and the using custom **converters** registered with the
154 module-level :func:`register_converter` function allow you to easily do that.
155
156 *detect_types* defaults to 0 (i. e. off, no type detection), you can set it to
157 any combination of :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES` to turn
158 type detection on.
159
160 By default, the :mod:`sqlite3` module uses its :class:`Connection` class for the
161 connect call. You can, however, subclass the :class:`Connection` class and make
162 :func:`connect` use your class instead by providing your class for the *factory*
163 parameter.
164
165 Consult the section :ref:`sqlite3-types` of this manual for details.
166
167 The :mod:`sqlite3` module internally uses a statement cache to avoid SQL parsing
168 overhead. If you want to explicitly set the number of statements that are cached
169 for the connection, you can set the *cached_statements* parameter. The currently
170 implemented default is to cache 100 statements.
171
172
173.. function:: register_converter(typename, callable)
174
175 Registers a callable to convert a bytestring from the database into a custom
176 Python type. The callable will be invoked for all database values that are of
177 the type *typename*. Confer the parameter *detect_types* of the :func:`connect`
178 function for how the type detection works. Note that the case of *typename* and
179 the name of the type in your query must match!
180
181
182.. function:: register_adapter(type, callable)
183
184 Registers a callable to convert the custom Python type *type* into one of
185 SQLite's supported types. The callable *callable* accepts as single parameter
Georg Brandl5c106642007-11-29 17:41:05 +0000186 the Python value, and must return a value of the following types: int,
Georg Brandlf6945182008-02-01 11:56:49 +0000187 float, str, bytes (UTF-8 encoded) or buffer.
Georg Brandl116aa622007-08-15 14:28:22 +0000188
189
190.. function:: complete_statement(sql)
191
192 Returns :const:`True` if the string *sql* contains one or more complete SQL
193 statements terminated by semicolons. It does not verify that the SQL is
194 syntactically correct, only that there are no unclosed string literals and the
195 statement is terminated by a semicolon.
196
197 This can be used to build a shell for SQLite, as in the following example:
198
199
200 .. literalinclude:: ../includes/sqlite3/complete_statement.py
201
202
203.. function:: enable_callback_tracebacks(flag)
204
205 By default you will not get any tracebacks in user-defined functions,
206 aggregates, converters, authorizer callbacks etc. If you want to debug them, you
207 can call this function with *flag* as True. Afterwards, you will get tracebacks
208 from callbacks on ``sys.stderr``. Use :const:`False` to disable the feature
209 again.
210
211
212.. _sqlite3-connection-objects:
213
214Connection Objects
215------------------
216
217A :class:`Connection` instance has the following attributes and methods:
218
219.. attribute:: Connection.isolation_level
220
221 Get or set the current isolation level. None for autocommit mode or one of
222 "DEFERRED", "IMMEDIATE" or "EXLUSIVE". See section
223 :ref:`sqlite3-controlling-transactions` for a more detailed explanation.
224
225
226.. method:: Connection.cursor([cursorClass])
227
228 The cursor method accepts a single optional parameter *cursorClass*. If
229 supplied, this must be a custom cursor class that extends
230 :class:`sqlite3.Cursor`.
231
232
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000233.. method:: Connection.commit()
234
235 This method commits the current transaction. If you don't call this method,
236 anything you did since the last call to commit() is not visible from from
237 other database connections. If you wonder why you don't see the data you've
238 written to the database, please check you didn't forget to call this method.
239
240.. method:: Connection.rollback()
241
242 This method rolls back any changes to the database since the last call to
243 :meth:`commit`.
244
245.. method:: Connection.close()
246
247 This closes the database connection. Note that this does not automatically
248 call :meth:`commit`. If you just close your database connection without
249 calling :meth:`commit` first, your changes will be lost!
250
Georg Brandl116aa622007-08-15 14:28:22 +0000251.. method:: Connection.execute(sql, [parameters])
252
253 This is a nonstandard shortcut that creates an intermediate cursor object by
254 calling the cursor method, then calls the cursor's :meth:`execute` method with
255 the parameters given.
256
257
258.. method:: Connection.executemany(sql, [parameters])
259
260 This is a nonstandard shortcut that creates an intermediate cursor object by
261 calling the cursor method, then calls the cursor's :meth:`executemany` method
262 with the parameters given.
263
264
265.. method:: Connection.executescript(sql_script)
266
267 This is a nonstandard shortcut that creates an intermediate cursor object by
268 calling the cursor method, then calls the cursor's :meth:`executescript` method
269 with the parameters given.
270
271
272.. method:: Connection.create_function(name, num_params, func)
273
274 Creates a user-defined function that you can later use from within SQL
275 statements under the function name *name*. *num_params* is the number of
276 parameters the function accepts, and *func* is a Python callable that is called
277 as the SQL function.
278
Georg Brandlf6945182008-02-01 11:56:49 +0000279 The function can return any of the types supported by SQLite: bytes, str, int,
Georg Brandl5c106642007-11-29 17:41:05 +0000280 float, buffer and None.
Georg Brandl116aa622007-08-15 14:28:22 +0000281
282 Example:
283
284 .. literalinclude:: ../includes/sqlite3/md5func.py
285
286
287.. method:: Connection.create_aggregate(name, num_params, aggregate_class)
288
289 Creates a user-defined aggregate function.
290
291 The aggregate class must implement a ``step`` method, which accepts the number
292 of parameters *num_params*, and a ``finalize`` method which will return the
293 final result of the aggregate.
294
295 The ``finalize`` method can return any of the types supported by SQLite:
Georg Brandlf6945182008-02-01 11:56:49 +0000296 bytes, str, int, float, buffer and None.
Georg Brandl116aa622007-08-15 14:28:22 +0000297
298 Example:
299
300 .. literalinclude:: ../includes/sqlite3/mysumaggr.py
301
302
303.. method:: Connection.create_collation(name, callable)
304
305 Creates a collation with the specified *name* and *callable*. The callable will
306 be passed two string arguments. It should return -1 if the first is ordered
307 lower than the second, 0 if they are ordered equal and 1 if the first is ordered
308 higher than the second. Note that this controls sorting (ORDER BY in SQL) so
309 your comparisons don't affect other SQL operations.
310
311 Note that the callable will get its parameters as Python bytestrings, which will
312 normally be encoded in UTF-8.
313
314 The following example shows a custom collation that sorts "the wrong way":
315
316 .. literalinclude:: ../includes/sqlite3/collation_reverse.py
317
318 To remove a collation, call ``create_collation`` with None as callable::
319
320 con.create_collation("reverse", None)
321
322
323.. method:: Connection.interrupt()
324
325 You can call this method from a different thread to abort any queries that might
326 be executing on the connection. The query will then abort and the caller will
327 get an exception.
328
329
330.. method:: Connection.set_authorizer(authorizer_callback)
331
332 This routine registers a callback. The callback is invoked for each attempt to
333 access a column of a table in the database. The callback should return
334 :const:`SQLITE_OK` if access is allowed, :const:`SQLITE_DENY` if the entire SQL
335 statement should be aborted with an error and :const:`SQLITE_IGNORE` if the
336 column should be treated as a NULL value. These constants are available in the
337 :mod:`sqlite3` module.
338
339 The first argument to the callback signifies what kind of operation is to be
340 authorized. The second and third argument will be arguments or :const:`None`
341 depending on the first argument. The 4th argument is the name of the database
342 ("main", "temp", etc.) if applicable. The 5th argument is the name of the
343 inner-most trigger or view that is responsible for the access attempt or
344 :const:`None` if this access attempt is directly from input SQL code.
345
346 Please consult the SQLite documentation about the possible values for the first
347 argument and the meaning of the second and third argument depending on the first
348 one. All necessary constants are available in the :mod:`sqlite3` module.
349
350
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000351.. method:: Connection.set_progress_handler(handler, n)
352
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000353 This routine registers a callback. The callback is invoked for every *n*
354 instructions of the SQLite virtual machine. This is useful if you want to
355 get called from SQLite during long-running operations, for example to update
356 a GUI.
357
358 If you want to clear any previously installed progress handler, call the
359 method with :const:`None` for *handler*.
360
361
Georg Brandl116aa622007-08-15 14:28:22 +0000362.. attribute:: Connection.row_factory
363
364 You can change this attribute to a callable that accepts the cursor and the
365 original row as a tuple and will return the real result row. This way, you can
366 implement more advanced ways of returning results, such as returning an object
367 that can also access columns by name.
368
369 Example:
370
371 .. literalinclude:: ../includes/sqlite3/row_factory.py
372
373 If returning a tuple doesn't suffice and you want name-based access to
374 columns, you should consider setting :attr:`row_factory` to the
375 highly-optimized :class:`sqlite3.Row` type. :class:`Row` provides both
376 index-based and case-insensitive name-based access to columns with almost no
377 memory overhead. It will probably be better than your own custom
378 dictionary-based approach or even a db_row based solution.
379
Christian Heimes5b5e81c2007-12-31 16:14:33 +0000380 .. XXX what's a db_row-based solution?
Georg Brandl116aa622007-08-15 14:28:22 +0000381
382
383.. attribute:: Connection.text_factory
384
385 Using this attribute you can control what objects are returned for the TEXT data
Georg Brandlf6945182008-02-01 11:56:49 +0000386 type. By default, this attribute is set to :class:`str` and the
387 :mod:`sqlite3` module will return strings for TEXT. If you want to
388 return bytestrings instead, you can set it to :class:`bytes`.
Georg Brandl116aa622007-08-15 14:28:22 +0000389
Georg Brandlf6945182008-02-01 11:56:49 +0000390 For efficiency reasons, there's also a way to return :class:`str` objects
391 only for non-ASCII data, and :class:`bytes` otherwise. To activate it, set
392 this attribute to :const:`sqlite3.OptimizedUnicode`.
Georg Brandl116aa622007-08-15 14:28:22 +0000393
394 You can also set it to any other callable that accepts a single bytestring
395 parameter and returns the resulting object.
396
397 See the following example code for illustration:
398
399 .. literalinclude:: ../includes/sqlite3/text_factory.py
400
401
402.. attribute:: Connection.total_changes
403
404 Returns the total number of database rows that have been modified, inserted, or
405 deleted since the database connection was opened.
406
407
Christian Heimesbbe741d2008-03-28 10:53:29 +0000408.. attribute:: Connection.iterdump
409
410 Returns an iterator to dump the database in an SQL text format. Useful when
411 saving an in-memory database for later restoration. This function provides
412 the same capabilities as the :kbd:`.dump` command in the :program:`sqlite3`
413 shell.
414
Christian Heimesbbe741d2008-03-28 10:53:29 +0000415 Example::
416
417 # Convert file existing_db.db to SQL dump file dump.sql
418 import sqlite3, os
419
420 con = sqlite3.connect('existing_db.db')
421 full_dump = os.linesep.join([line for line in con.iterdump()])
422 f = open('dump.sql', 'w')
423 f.writelines(full_dump)
424 f.close()
425
426
Georg Brandl116aa622007-08-15 14:28:22 +0000427.. _sqlite3-cursor-objects:
428
429Cursor Objects
430--------------
431
432A :class:`Cursor` instance has the following attributes and methods:
433
434
435.. method:: Cursor.execute(sql, [parameters])
436
Christian Heimesfdab48e2008-01-20 09:06:41 +0000437 Executes an SQL statement. The SQL statement may be parametrized (i. e.
Georg Brandl116aa622007-08-15 14:28:22 +0000438 placeholders instead of SQL literals). The :mod:`sqlite3` module supports two
439 kinds of placeholders: question marks (qmark style) and named placeholders
440 (named style).
441
442 This example shows how to use parameters with qmark style:
443
444 .. literalinclude:: ../includes/sqlite3/execute_1.py
445
446 This example shows how to use the named style:
447
448 .. literalinclude:: ../includes/sqlite3/execute_2.py
449
450 :meth:`execute` will only execute a single SQL statement. If you try to execute
451 more than one statement with it, it will raise a Warning. Use
452 :meth:`executescript` if you want to execute multiple SQL statements with one
453 call.
454
455
456.. method:: Cursor.executemany(sql, seq_of_parameters)
457
Christian Heimesfdab48e2008-01-20 09:06:41 +0000458 Executes an SQL command against all parameter sequences or mappings found in
Georg Brandl9afde1c2007-11-01 20:32:30 +0000459 the sequence *sql*. The :mod:`sqlite3` module also allows using an
460 :term:`iterator` yielding parameters instead of a sequence.
Georg Brandl116aa622007-08-15 14:28:22 +0000461
462 .. literalinclude:: ../includes/sqlite3/executemany_1.py
463
Georg Brandl9afde1c2007-11-01 20:32:30 +0000464 Here's a shorter example using a :term:`generator`:
Georg Brandl116aa622007-08-15 14:28:22 +0000465
466 .. literalinclude:: ../includes/sqlite3/executemany_2.py
467
468
469.. method:: Cursor.executescript(sql_script)
470
471 This is a nonstandard convenience method for executing multiple SQL statements
472 at once. It issues a COMMIT statement first, then executes the SQL script it
473 gets as a parameter.
474
Georg Brandlf6945182008-02-01 11:56:49 +0000475 *sql_script* can be an instance of :class:`str` or :class:`bytes`.
Georg Brandl116aa622007-08-15 14:28:22 +0000476
477 Example:
478
479 .. literalinclude:: ../includes/sqlite3/executescript.py
480
481
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000482.. method:: Cursor.fetchone()
483
Christian Heimesfdab48e2008-01-20 09:06:41 +0000484 Fetches the next row of a query result set, returning a single sequence,
485 or ``None`` when no more data is available.
486
487
488.. method:: Cursor.fetchmany([size=cursor.arraysize])
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000489
Christian Heimesfdab48e2008-01-20 09:06:41 +0000490 Fetches the next set of rows of a query result, returning a list. An empty
491 list is returned when no more rows are available.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000492
Christian Heimesfdab48e2008-01-20 09:06:41 +0000493 The number of rows to fetch per call is specified by the *size* parameter.
494 If it is not given, the cursor's arraysize determines the number of rows
495 to be fetched. The method should try to fetch as many rows as indicated by
496 the size parameter. If this is not possible due to the specified number of
497 rows not being available, fewer rows may be returned.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000498
Christian Heimesfdab48e2008-01-20 09:06:41 +0000499 Note there are performance considerations involved with the *size* parameter.
500 For optimal performance, it is usually best to use the arraysize attribute.
501 If the *size* parameter is used, then it is best for it to retain the same
502 value from one :meth:`fetchmany` call to the next.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000503
504.. method:: Cursor.fetchall()
Christian Heimesfdab48e2008-01-20 09:06:41 +0000505
506 Fetches all (remaining) rows of a query result, returning a list. Note that
507 the cursor's arraysize attribute can affect the performance of this operation.
508 An empty list is returned when no rows are available.
509
510
Georg Brandl116aa622007-08-15 14:28:22 +0000511.. attribute:: Cursor.rowcount
512
513 Although the :class:`Cursor` class of the :mod:`sqlite3` module implements this
514 attribute, the database engine's own support for the determination of "rows
515 affected"/"rows selected" is quirky.
516
Georg Brandl116aa622007-08-15 14:28:22 +0000517 For ``DELETE`` statements, SQLite reports :attr:`rowcount` as 0 if you make a
518 ``DELETE FROM table`` without any condition.
519
520 For :meth:`executemany` statements, the number of modifications are summed up
521 into :attr:`rowcount`.
522
523 As required by the Python DB API Spec, the :attr:`rowcount` attribute "is -1 in
524 case no executeXX() has been performed on the cursor or the rowcount of the last
525 operation is not determinable by the interface".
526
Guido van Rossum04110fb2007-08-24 16:32:05 +0000527 This includes ``SELECT`` statements because we cannot determine the number of
528 rows a query produced until all rows were fetched.
529
Gerhard Häringd3372792008-03-29 19:13:55 +0000530.. attribute:: Cursor.lastrowid
531
532 This read-only attribute provides the rowid of the last modified row. It is
533 only set if you issued a ``INSERT`` statement using the :meth:`execute`
534 method. For operations other than ``INSERT`` or when :meth:`executemany` is
535 called, :attr:`lastrowid` is set to :const:`None`.
Georg Brandl116aa622007-08-15 14:28:22 +0000536
537.. _sqlite3-types:
538
539SQLite and Python types
540-----------------------
541
542
543Introduction
544^^^^^^^^^^^^
545
546SQLite natively supports the following types: NULL, INTEGER, REAL, TEXT, BLOB.
547
548The following Python types can thus be sent to SQLite without any problem:
549
Georg Brandlf6945182008-02-01 11:56:49 +0000550+-------------------------------+-------------+
551| Python type | SQLite type |
552+===============================+=============+
553| ``None`` | NULL |
554+-------------------------------+-------------+
555| :class:`int` | INTEGER |
556+-------------------------------+-------------+
557| :class:`float` | REAL |
558+-------------------------------+-------------+
559| :class:`bytes` (UTF8-encoded) | TEXT |
560+-------------------------------+-------------+
561| :class:`str` | TEXT |
562+-------------------------------+-------------+
563| :class:`buffer` | BLOB |
564+-------------------------------+-------------+
Georg Brandl116aa622007-08-15 14:28:22 +0000565
566This is how SQLite types are converted to Python types by default:
567
568+-------------+---------------------------------------------+
569| SQLite type | Python type |
570+=============+=============================================+
571| ``NULL`` | None |
572+-------------+---------------------------------------------+
Georg Brandl5c106642007-11-29 17:41:05 +0000573| ``INTEGER`` | int |
Georg Brandl116aa622007-08-15 14:28:22 +0000574+-------------+---------------------------------------------+
575| ``REAL`` | float |
576+-------------+---------------------------------------------+
Georg Brandlf6945182008-02-01 11:56:49 +0000577| ``TEXT`` | depends on text_factory, str by default |
Georg Brandl116aa622007-08-15 14:28:22 +0000578+-------------+---------------------------------------------+
579| ``BLOB`` | buffer |
580+-------------+---------------------------------------------+
581
582The type system of the :mod:`sqlite3` module is extensible in two ways: you can
583store additional Python types in a SQLite database via object adaptation, and
584you can let the :mod:`sqlite3` module convert SQLite types to different Python
585types via converters.
586
587
588Using adapters to store additional Python types in SQLite databases
589^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
590
591As described before, SQLite supports only a limited set of types natively. To
592use other Python types with SQLite, you must **adapt** them to one of the
Georg Brandl5c106642007-11-29 17:41:05 +0000593sqlite3 module's supported types for SQLite: one of NoneType, int, float,
Georg Brandlf6945182008-02-01 11:56:49 +0000594str, bytes, buffer.
Georg Brandl116aa622007-08-15 14:28:22 +0000595
596The :mod:`sqlite3` module uses Python object adaptation, as described in
597:pep:`246` for this. The protocol to use is :class:`PrepareProtocol`.
598
599There are two ways to enable the :mod:`sqlite3` module to adapt a custom Python
600type to one of the supported ones.
601
602
603Letting your object adapt itself
604""""""""""""""""""""""""""""""""
605
606This is a good approach if you write the class yourself. Let's suppose you have
607a class like this::
608
609 class Point(object):
610 def __init__(self, x, y):
611 self.x, self.y = x, y
612
613Now you want to store the point in a single SQLite column. First you'll have to
614choose one of the supported types first to be used for representing the point.
615Let's just use str and separate the coordinates using a semicolon. Then you need
616to give your class a method ``__conform__(self, protocol)`` which must return
617the converted value. The parameter *protocol* will be :class:`PrepareProtocol`.
618
619.. literalinclude:: ../includes/sqlite3/adapter_point_1.py
620
621
622Registering an adapter callable
623"""""""""""""""""""""""""""""""
624
625The other possibility is to create a function that converts the type to the
626string representation and register the function with :meth:`register_adapter`.
627
Georg Brandl116aa622007-08-15 14:28:22 +0000628.. literalinclude:: ../includes/sqlite3/adapter_point_2.py
629
630The :mod:`sqlite3` module has two default adapters for Python's built-in
631:class:`datetime.date` and :class:`datetime.datetime` types. Now let's suppose
632we want to store :class:`datetime.datetime` objects not in ISO representation,
633but as a Unix timestamp.
634
635.. literalinclude:: ../includes/sqlite3/adapter_datetime.py
636
637
638Converting SQLite values to custom Python types
639^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
640
641Writing an adapter lets you send custom Python types to SQLite. But to make it
642really useful we need to make the Python to SQLite to Python roundtrip work.
643
644Enter converters.
645
646Let's go back to the :class:`Point` class. We stored the x and y coordinates
647separated via semicolons as strings in SQLite.
648
649First, we'll define a converter function that accepts the string as a parameter
650and constructs a :class:`Point` object from it.
651
652.. note::
653
654 Converter functions **always** get called with a string, no matter under which
655 data type you sent the value to SQLite.
656
657.. note::
658
659 Converter names are looked up in a case-sensitive manner.
660
661::
662
663 def convert_point(s):
664 x, y = map(float, s.split(";"))
665 return Point(x, y)
666
667Now you need to make the :mod:`sqlite3` module know that what you select from
668the database is actually a point. There are two ways of doing this:
669
670* Implicitly via the declared type
671
672* Explicitly via the column name
673
674Both ways are described in section :ref:`sqlite3-module-contents`, in the entries
675for the constants :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`.
676
677The following example illustrates both approaches.
678
679.. literalinclude:: ../includes/sqlite3/converter_point.py
680
681
682Default adapters and converters
683^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
684
685There are default adapters for the date and datetime types in the datetime
686module. They will be sent as ISO dates/ISO timestamps to SQLite.
687
688The default converters are registered under the name "date" for
689:class:`datetime.date` and under the name "timestamp" for
690:class:`datetime.datetime`.
691
692This way, you can use date/timestamps from Python without any additional
693fiddling in most cases. The format of the adapters is also compatible with the
694experimental SQLite date/time functions.
695
696The following example demonstrates this.
697
698.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py
699
700
701.. _sqlite3-controlling-transactions:
702
703Controlling Transactions
704------------------------
705
706By default, the :mod:`sqlite3` module opens transactions implicitly before a
707Data Modification Language (DML) statement (i.e. INSERT/UPDATE/DELETE/REPLACE),
708and commits transactions implicitly before a non-DML, non-query statement (i. e.
709anything other than SELECT/INSERT/UPDATE/DELETE/REPLACE).
710
711So if you are within a transaction and issue a command like ``CREATE TABLE
712...``, ``VACUUM``, ``PRAGMA``, the :mod:`sqlite3` module will commit implicitly
713before executing that command. There are two reasons for doing that. The first
714is that some of these commands don't work within transactions. The other reason
715is that pysqlite needs to keep track of the transaction state (if a transaction
716is active or not).
717
718You can control which kind of "BEGIN" statements pysqlite implicitly executes
719(or none at all) via the *isolation_level* parameter to the :func:`connect`
720call, or via the :attr:`isolation_level` property of connections.
721
722If you want **autocommit mode**, then set :attr:`isolation_level` to None.
723
724Otherwise leave it at its default, which will result in a plain "BEGIN"
725statement, or set it to one of SQLite's supported isolation levels: DEFERRED,
726IMMEDIATE or EXCLUSIVE.
727
Georg Brandl116aa622007-08-15 14:28:22 +0000728
729
730Using pysqlite efficiently
731--------------------------
732
733
734Using shortcut methods
735^^^^^^^^^^^^^^^^^^^^^^
736
737Using the nonstandard :meth:`execute`, :meth:`executemany` and
738:meth:`executescript` methods of the :class:`Connection` object, your code can
739be written more concisely because you don't have to create the (often
740superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
741objects are created implicitly and these shortcut methods return the cursor
742objects. This way, you can execute a SELECT statement and iterate over it
743directly using only a single call on the :class:`Connection` object.
744
745.. literalinclude:: ../includes/sqlite3/shortcut_methods.py
746
747
748Accessing columns by name instead of by index
749^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
750
751One useful feature of the :mod:`sqlite3` module is the builtin
752:class:`sqlite3.Row` class designed to be used as a row factory.
753
754Rows wrapped with this class can be accessed both by index (like tuples) and
755case-insensitively by name:
756
757.. literalinclude:: ../includes/sqlite3/rowclass.py
758
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000759
760Using the connection as a context manager
761^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
762
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000763Connection objects can be used as context managers
764that automatically commit or rollback transactions. In the event of an
765exception, the transaction is rolled back; otherwise, the transaction is
766committed:
767
768.. literalinclude:: ../includes/sqlite3/ctx_manager.py