blob: 0603738c67ada646c44d0a82b3f7bcd4edc5d1d2 [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
Georg Brandl8a1e4c42009-05-25 21:13:36 +000016sqlite3 was written by Gerhard Häring and provides a SQL interface compliant
Georg Brandl116aa622007-08-15 14:28:22 +000017with 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
Georg Brandl8a1e4c42009-05-25 21:13:36 +000053second argument to the cursor's :meth:`~Cursor.execute` method. (Other database
54modules may use a different placeholder, such as ``%s`` or ``:1``.) For
55example::
Georg Brandl116aa622007-08-15 14:28:22 +000056
57 # Never do this -- insecure!
58 symbol = 'IBM'
59 c.execute("... where symbol = '%s'" % symbol)
60
61 # Do this instead
62 t = (symbol,)
63 c.execute('select * from stocks where symbol=?', t)
64
65 # Larger example
Georg Brandla971c652008-11-07 09:39:56 +000066 for t in [('2006-03-28', 'BUY', 'IBM', 1000, 45.00),
Georg Brandl116aa622007-08-15 14:28:22 +000067 ('2006-04-05', 'BUY', 'MSOFT', 1000, 72.00),
68 ('2006-04-06', 'SELL', 'IBM', 500, 53.00),
Georg Brandla971c652008-11-07 09:39:56 +000069 ]:
Georg Brandl116aa622007-08-15 14:28:22 +000070 c.execute('insert into stocks values (?,?,?,?,?)', t)
71
Georg Brandl9afde1c2007-11-01 20:32:30 +000072To retrieve data after executing a SELECT statement, you can either treat the
Benjamin Petersonf10a79a2008-10-11 00:49:57 +000073cursor as an :term:`iterator`, call the cursor's :meth:`~Cursor.fetchone` method to
74retrieve a single matching row, or call :meth:`~Cursor.fetchall` to get a list of the
Georg Brandl9afde1c2007-11-01 20:32:30 +000075matching rows.
Georg Brandl116aa622007-08-15 14:28:22 +000076
77This example uses the iterator form::
78
79 >>> c = conn.cursor()
80 >>> c.execute('select * from stocks order by price')
81 >>> for row in c:
Ezio Melottif3880532009-09-13 08:09:56 +000082 ... print(row)
Georg Brandl116aa622007-08-15 14:28:22 +000083 ...
Ezio Melottif3880532009-09-13 08:09:56 +000084 ('2006-01-05', 'BUY', 'RHAT', 100, 35.14)
85 ('2006-03-28', 'BUY', 'IBM', 1000, 45.0)
86 ('2006-04-06', 'SELL', 'IBM', 500, 53.0)
87 ('2006-04-05', 'BUY', 'MSOFT', 1000, 72.0)
Georg Brandl116aa622007-08-15 14:28:22 +000088 >>>
89
90
91.. seealso::
92
93 http://www.pysqlite.org
Georg Brandl8a1e4c42009-05-25 21:13:36 +000094 The pysqlite web page -- sqlite3 is developed externally under the name
95 "pysqlite".
Georg Brandl116aa622007-08-15 14:28:22 +000096
97 http://www.sqlite.org
Georg Brandl8a1e4c42009-05-25 21:13:36 +000098 The SQLite web page; the documentation describes the syntax and the
99 available data types for the supported SQL dialect.
Georg Brandl116aa622007-08-15 14:28:22 +0000100
101 :pep:`249` - Database API Specification 2.0
102 PEP written by Marc-André Lemburg.
103
104
105.. _sqlite3-module-contents:
106
107Module functions and constants
108------------------------------
109
110
111.. data:: PARSE_DECLTYPES
112
113 This constant is meant to be used with the *detect_types* parameter of the
114 :func:`connect` function.
115
116 Setting it makes the :mod:`sqlite3` module parse the declared type for each
Christian Heimes81ee3ef2008-05-04 22:42:01 +0000117 column it returns. It will parse out the first word of the declared type,
118 i. e. for "integer primary key", it will parse out "integer", or for
119 "number(10)" it will parse out "number". Then for that column, it will look
120 into the converters dictionary and use the converter function registered for
121 that type there.
Georg Brandl116aa622007-08-15 14:28:22 +0000122
123
124.. data:: PARSE_COLNAMES
125
126 This constant is meant to be used with the *detect_types* parameter of the
127 :func:`connect` function.
128
129 Setting this makes the SQLite interface parse the column name for each column it
130 returns. It will look for a string formed [mytype] in there, and then decide
131 that 'mytype' is the type of the column. It will try to find an entry of
132 'mytype' in the converters dictionary and then use the converter function found
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000133 there to return the value. The column name found in :attr:`Cursor.description`
Georg Brandl116aa622007-08-15 14:28:22 +0000134 is only the first word of the column name, i. e. if you use something like
135 ``'as "x [datetime]"'`` in your SQL, then we will parse out everything until the
136 first blank for the column name: the column name would simply be "x".
137
138
Georg Brandl914a2182010-10-06 08:13:26 +0000139.. function:: connect(database[, timeout, detect_types, isolation_level, check_same_thread, factory, cached_statements])
Georg Brandl116aa622007-08-15 14:28:22 +0000140
141 Opens a connection to the SQLite database file *database*. You can use
142 ``":memory:"`` to open a database connection to a database that resides in RAM
143 instead of on disk.
144
145 When a database is accessed by multiple connections, and one of the processes
146 modifies the database, the SQLite database is locked until that transaction is
147 committed. The *timeout* parameter specifies how long the connection should wait
148 for the lock to go away until raising an exception. The default for the timeout
149 parameter is 5.0 (five seconds).
150
151 For the *isolation_level* parameter, please see the
152 :attr:`Connection.isolation_level` property of :class:`Connection` objects.
153
154 SQLite natively supports only the types TEXT, INTEGER, FLOAT, BLOB and NULL. If
155 you want to use other types you must add support for them yourself. The
156 *detect_types* parameter and the using custom **converters** registered with the
157 module-level :func:`register_converter` function allow you to easily do that.
158
159 *detect_types* defaults to 0 (i. e. off, no type detection), you can set it to
160 any combination of :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES` to turn
161 type detection on.
162
163 By default, the :mod:`sqlite3` module uses its :class:`Connection` class for the
164 connect call. You can, however, subclass the :class:`Connection` class and make
165 :func:`connect` use your class instead by providing your class for the *factory*
166 parameter.
167
168 Consult the section :ref:`sqlite3-types` of this manual for details.
169
170 The :mod:`sqlite3` module internally uses a statement cache to avoid SQL parsing
171 overhead. If you want to explicitly set the number of statements that are cached
172 for the connection, you can set the *cached_statements* parameter. The currently
173 implemented default is to cache 100 statements.
174
175
176.. function:: register_converter(typename, callable)
177
178 Registers a callable to convert a bytestring from the database into a custom
179 Python type. The callable will be invoked for all database values that are of
180 the type *typename*. Confer the parameter *detect_types* of the :func:`connect`
181 function for how the type detection works. Note that the case of *typename* and
182 the name of the type in your query must match!
183
184
185.. function:: register_adapter(type, callable)
186
187 Registers a callable to convert the custom Python type *type* into one of
188 SQLite's supported types. The callable *callable* accepts as single parameter
Georg Brandl5c106642007-11-29 17:41:05 +0000189 the Python value, and must return a value of the following types: int,
Antoine Pitrouf37d0a12010-02-02 23:01:36 +0000190 float, str or bytes.
Georg Brandl116aa622007-08-15 14:28:22 +0000191
192
193.. function:: complete_statement(sql)
194
195 Returns :const:`True` if the string *sql* contains one or more complete SQL
196 statements terminated by semicolons. It does not verify that the SQL is
197 syntactically correct, only that there are no unclosed string literals and the
198 statement is terminated by a semicolon.
199
200 This can be used to build a shell for SQLite, as in the following example:
201
202
203 .. literalinclude:: ../includes/sqlite3/complete_statement.py
204
205
206.. function:: enable_callback_tracebacks(flag)
207
208 By default you will not get any tracebacks in user-defined functions,
209 aggregates, converters, authorizer callbacks etc. If you want to debug them, you
210 can call this function with *flag* as True. Afterwards, you will get tracebacks
211 from callbacks on ``sys.stderr``. Use :const:`False` to disable the feature
212 again.
213
214
215.. _sqlite3-connection-objects:
216
217Connection Objects
218------------------
219
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000220.. class:: Connection
221
222 A SQLite database connection has the following attributes and methods:
Georg Brandl116aa622007-08-15 14:28:22 +0000223
224.. attribute:: Connection.isolation_level
225
Benjamin Peterson4469d0c2008-11-30 22:46:23 +0000226 Get or set the current isolation level. :const:`None` for autocommit mode or
227 one of "DEFERRED", "IMMEDIATE" or "EXCLUSIVE". See section
Georg Brandl116aa622007-08-15 14:28:22 +0000228 :ref:`sqlite3-controlling-transactions` for a more detailed explanation.
229
230
231.. method:: Connection.cursor([cursorClass])
232
233 The cursor method accepts a single optional parameter *cursorClass*. If
234 supplied, this must be a custom cursor class that extends
235 :class:`sqlite3.Cursor`.
236
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000237.. method:: Connection.commit()
238
239 This method commits the current transaction. If you don't call this method,
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000240 anything you did since the last call to ``commit()`` is not visible from from
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000241 other database connections. If you wonder why you don't see the data you've
242 written to the database, please check you didn't forget to call this method.
243
244.. method:: Connection.rollback()
245
246 This method rolls back any changes to the database since the last call to
247 :meth:`commit`.
248
249.. method:: Connection.close()
250
251 This closes the database connection. Note that this does not automatically
252 call :meth:`commit`. If you just close your database connection without
253 calling :meth:`commit` first, your changes will be lost!
254
Georg Brandl116aa622007-08-15 14:28:22 +0000255.. method:: Connection.execute(sql, [parameters])
256
257 This is a nonstandard shortcut that creates an intermediate cursor object by
Georg Brandlab32fec2010-11-26 08:49:15 +0000258 calling the cursor method, then calls the cursor's :meth:`execute
259 <Cursor.execute>` method with the parameters given.
Georg Brandl116aa622007-08-15 14:28:22 +0000260
261
262.. method:: Connection.executemany(sql, [parameters])
263
264 This is a nonstandard shortcut that creates an intermediate cursor object by
Georg Brandlab32fec2010-11-26 08:49:15 +0000265 calling the cursor method, then calls the cursor's :meth:`executemany
266 <Cursor.executemany>` method with the parameters given.
Georg Brandl116aa622007-08-15 14:28:22 +0000267
268
269.. method:: Connection.executescript(sql_script)
270
271 This is a nonstandard shortcut that creates an intermediate cursor object by
Georg Brandlab32fec2010-11-26 08:49:15 +0000272 calling the cursor method, then calls the cursor's :meth:`executescript
273 <Cursor.executescript>` method with the parameters given.
Georg Brandl116aa622007-08-15 14:28:22 +0000274
275
276.. method:: Connection.create_function(name, num_params, func)
277
278 Creates a user-defined function that you can later use from within SQL
279 statements under the function name *name*. *num_params* is the number of
280 parameters the function accepts, and *func* is a Python callable that is called
281 as the SQL function.
282
Georg Brandlf6945182008-02-01 11:56:49 +0000283 The function can return any of the types supported by SQLite: bytes, str, int,
Antoine Pitrouf37d0a12010-02-02 23:01:36 +0000284 float and None.
Georg Brandl116aa622007-08-15 14:28:22 +0000285
286 Example:
287
288 .. literalinclude:: ../includes/sqlite3/md5func.py
289
290
291.. method:: Connection.create_aggregate(name, num_params, aggregate_class)
292
293 Creates a user-defined aggregate function.
294
295 The aggregate class must implement a ``step`` method, which accepts the number
296 of parameters *num_params*, and a ``finalize`` method which will return the
297 final result of the aggregate.
298
299 The ``finalize`` method can return any of the types supported by SQLite:
Antoine Pitrouf37d0a12010-02-02 23:01:36 +0000300 bytes, str, int, float and None.
Georg Brandl116aa622007-08-15 14:28:22 +0000301
302 Example:
303
304 .. literalinclude:: ../includes/sqlite3/mysumaggr.py
305
306
307.. method:: Connection.create_collation(name, callable)
308
309 Creates a collation with the specified *name* and *callable*. The callable will
310 be passed two string arguments. It should return -1 if the first is ordered
311 lower than the second, 0 if they are ordered equal and 1 if the first is ordered
312 higher than the second. Note that this controls sorting (ORDER BY in SQL) so
313 your comparisons don't affect other SQL operations.
314
315 Note that the callable will get its parameters as Python bytestrings, which will
316 normally be encoded in UTF-8.
317
318 The following example shows a custom collation that sorts "the wrong way":
319
320 .. literalinclude:: ../includes/sqlite3/collation_reverse.py
321
322 To remove a collation, call ``create_collation`` with None as callable::
323
324 con.create_collation("reverse", None)
325
326
327.. method:: Connection.interrupt()
328
329 You can call this method from a different thread to abort any queries that might
330 be executing on the connection. The query will then abort and the caller will
331 get an exception.
332
333
334.. method:: Connection.set_authorizer(authorizer_callback)
335
336 This routine registers a callback. The callback is invoked for each attempt to
337 access a column of a table in the database. The callback should return
338 :const:`SQLITE_OK` if access is allowed, :const:`SQLITE_DENY` if the entire SQL
339 statement should be aborted with an error and :const:`SQLITE_IGNORE` if the
340 column should be treated as a NULL value. These constants are available in the
341 :mod:`sqlite3` module.
342
343 The first argument to the callback signifies what kind of operation is to be
344 authorized. The second and third argument will be arguments or :const:`None`
345 depending on the first argument. The 4th argument is the name of the database
346 ("main", "temp", etc.) if applicable. The 5th argument is the name of the
347 inner-most trigger or view that is responsible for the access attempt or
348 :const:`None` if this access attempt is directly from input SQL code.
349
350 Please consult the SQLite documentation about the possible values for the first
351 argument and the meaning of the second and third argument depending on the first
352 one. All necessary constants are available in the :mod:`sqlite3` module.
353
354
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000355.. method:: Connection.set_progress_handler(handler, n)
356
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000357 This routine registers a callback. The callback is invoked for every *n*
358 instructions of the SQLite virtual machine. This is useful if you want to
359 get called from SQLite during long-running operations, for example to update
360 a GUI.
361
362 If you want to clear any previously installed progress handler, call the
363 method with :const:`None` for *handler*.
364
365
Georg Brandl116aa622007-08-15 14:28:22 +0000366.. attribute:: Connection.row_factory
367
368 You can change this attribute to a callable that accepts the cursor and the
369 original row as a tuple and will return the real result row. This way, you can
370 implement more advanced ways of returning results, such as returning an object
371 that can also access columns by name.
372
373 Example:
374
375 .. literalinclude:: ../includes/sqlite3/row_factory.py
376
377 If returning a tuple doesn't suffice and you want name-based access to
378 columns, you should consider setting :attr:`row_factory` to the
379 highly-optimized :class:`sqlite3.Row` type. :class:`Row` provides both
380 index-based and case-insensitive name-based access to columns with almost no
381 memory overhead. It will probably be better than your own custom
382 dictionary-based approach or even a db_row based solution.
383
Christian Heimes5b5e81c2007-12-31 16:14:33 +0000384 .. XXX what's a db_row-based solution?
Georg Brandl116aa622007-08-15 14:28:22 +0000385
386
387.. attribute:: Connection.text_factory
388
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000389 Using this attribute you can control what objects are returned for the ``TEXT``
390 data type. By default, this attribute is set to :class:`str` and the
391 :mod:`sqlite3` module will return Unicode objects for ``TEXT``. If you want to
Georg Brandlf6945182008-02-01 11:56:49 +0000392 return bytestrings instead, you can set it to :class:`bytes`.
Georg Brandl116aa622007-08-15 14:28:22 +0000393
Georg Brandlf6945182008-02-01 11:56:49 +0000394 For efficiency reasons, there's also a way to return :class:`str` objects
395 only for non-ASCII data, and :class:`bytes` otherwise. To activate it, set
396 this attribute to :const:`sqlite3.OptimizedUnicode`.
Georg Brandl116aa622007-08-15 14:28:22 +0000397
398 You can also set it to any other callable that accepts a single bytestring
399 parameter and returns the resulting object.
400
401 See the following example code for illustration:
402
403 .. literalinclude:: ../includes/sqlite3/text_factory.py
404
405
406.. attribute:: Connection.total_changes
407
408 Returns the total number of database rows that have been modified, inserted, or
409 deleted since the database connection was opened.
410
411
Christian Heimesbbe741d2008-03-28 10:53:29 +0000412.. attribute:: Connection.iterdump
413
414 Returns an iterator to dump the database in an SQL text format. Useful when
415 saving an in-memory database for later restoration. This function provides
416 the same capabilities as the :kbd:`.dump` command in the :program:`sqlite3`
417 shell.
418
Christian Heimesbbe741d2008-03-28 10:53:29 +0000419 Example::
420
421 # Convert file existing_db.db to SQL dump file dump.sql
422 import sqlite3, os
423
424 con = sqlite3.connect('existing_db.db')
Georg Brandla971c652008-11-07 09:39:56 +0000425 with open('dump.sql', 'w') as f:
426 for line in con.iterdump():
427 f.write('%s\n' % line)
Christian Heimesbbe741d2008-03-28 10:53:29 +0000428
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
Georg Brandlab32fec2010-11-26 08:49:15 +0000437 A :class:`Cursor` instance 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
Georg Brandl48310cd2009-01-03 21:18:54 +0000545 column where the last six items of each tuple are :const:`None`.
546
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000547 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
Georg Brandl48310cd2009-01-03 21:18:54 +0000557 :attr:`~Connection.row_factory` for :class:`Connection` objects.
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000558 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.
Georg Brandl48310cd2009-01-03 21:18:54 +0000565
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000566 .. method:: keys
567
568 This method returns a tuple of column names. Immediately after a query,
569 it is the first member of each tuple in :attr:`Cursor.description`.
570
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000571Let's assume we initialize a table as in the example given above::
572
573 conn = sqlite3.connect(":memory:")
574 c = conn.cursor()
575 c.execute('''create table stocks
576 (date text, trans text, symbol text,
577 qty real, price real)''')
578 c.execute("""insert into stocks
579 values ('2006-01-05','BUY','RHAT',100,35.14)""")
580 conn.commit()
581 c.close()
582
583Now we plug :class:`Row` in::
584
585 >>> conn.row_factory = sqlite3.Row
586 >>> c = conn.cursor()
587 >>> c.execute('select * from stocks')
588 <sqlite3.Cursor object at 0x7f4e7dd8fa80>
589 >>> r = c.fetchone()
590 >>> type(r)
Ezio Melottif3880532009-09-13 08:09:56 +0000591 <class 'sqlite3.Row'>
592 >>> tuple(r)
593 ('2006-01-05', 'BUY', 'RHAT', 100.0, 35.14)
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000594 >>> len(r)
595 5
596 >>> r[2]
Ezio Melottif3880532009-09-13 08:09:56 +0000597 'RHAT'
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000598 >>> r.keys()
599 ['date', 'trans', 'symbol', 'qty', 'price']
600 >>> r['qty']
601 100.0
Ezio Melottif3880532009-09-13 08:09:56 +0000602 >>> for member in r:
603 ... print(member)
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000604 ...
605 2006-01-05
606 BUY
607 RHAT
608 100.0
609 35.14
610
611
Georg Brandl116aa622007-08-15 14:28:22 +0000612.. _sqlite3-types:
613
614SQLite and Python types
615-----------------------
616
617
618Introduction
619^^^^^^^^^^^^
620
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000621SQLite natively supports the following types: ``NULL``, ``INTEGER``,
622``REAL``, ``TEXT``, ``BLOB``.
Georg Brandl116aa622007-08-15 14:28:22 +0000623
624The following Python types can thus be sent to SQLite without any problem:
625
Georg Brandlf6945182008-02-01 11:56:49 +0000626+-------------------------------+-------------+
627| Python type | SQLite type |
628+===============================+=============+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000629| :const:`None` | ``NULL`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000630+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000631| :class:`int` | ``INTEGER`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000632+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000633| :class:`float` | ``REAL`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000634+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000635| :class:`str` | ``TEXT`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000636+-------------------------------+-------------+
Antoine Pitrouf37d0a12010-02-02 23:01:36 +0000637| :class:`bytes` | ``BLOB`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000638+-------------------------------+-------------+
Georg Brandl116aa622007-08-15 14:28:22 +0000639
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000640
Georg Brandl116aa622007-08-15 14:28:22 +0000641This is how SQLite types are converted to Python types by default:
642
643+-------------+---------------------------------------------+
644| SQLite type | Python type |
645+=============+=============================================+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000646| ``NULL`` | :const:`None` |
Georg Brandl116aa622007-08-15 14:28:22 +0000647+-------------+---------------------------------------------+
Ezio Melottif3880532009-09-13 08:09:56 +0000648| ``INTEGER`` | :class:`int` |
Georg Brandl116aa622007-08-15 14:28:22 +0000649+-------------+---------------------------------------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000650| ``REAL`` | :class:`float` |
Georg Brandl116aa622007-08-15 14:28:22 +0000651+-------------+---------------------------------------------+
Georg Brandlf6945182008-02-01 11:56:49 +0000652| ``TEXT`` | depends on text_factory, str by default |
Georg Brandl116aa622007-08-15 14:28:22 +0000653+-------------+---------------------------------------------+
Antoine Pitrouf37d0a12010-02-02 23:01:36 +0000654| ``BLOB`` | :class:`bytes` |
Georg Brandl116aa622007-08-15 14:28:22 +0000655+-------------+---------------------------------------------+
656
657The type system of the :mod:`sqlite3` module is extensible in two ways: you can
658store additional Python types in a SQLite database via object adaptation, and
659you can let the :mod:`sqlite3` module convert SQLite types to different Python
660types via converters.
661
662
663Using adapters to store additional Python types in SQLite databases
664^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
665
666As described before, SQLite supports only a limited set of types natively. To
667use other Python types with SQLite, you must **adapt** them to one of the
Georg Brandl5c106642007-11-29 17:41:05 +0000668sqlite3 module's supported types for SQLite: one of NoneType, int, float,
Antoine Pitrouf37d0a12010-02-02 23:01:36 +0000669str, bytes.
Georg Brandl116aa622007-08-15 14:28:22 +0000670
671The :mod:`sqlite3` module uses Python object adaptation, as described in
672:pep:`246` for this. The protocol to use is :class:`PrepareProtocol`.
673
674There are two ways to enable the :mod:`sqlite3` module to adapt a custom Python
675type to one of the supported ones.
676
677
678Letting your object adapt itself
679""""""""""""""""""""""""""""""""
680
681This is a good approach if you write the class yourself. Let's suppose you have
682a class like this::
683
Éric Araujoda825ab2010-11-22 03:18:24 +0000684 class Point:
Georg Brandl116aa622007-08-15 14:28:22 +0000685 def __init__(self, x, y):
686 self.x, self.y = x, y
687
688Now you want to store the point in a single SQLite column. First you'll have to
689choose one of the supported types first to be used for representing the point.
690Let's just use str and separate the coordinates using a semicolon. Then you need
691to give your class a method ``__conform__(self, protocol)`` which must return
692the converted value. The parameter *protocol* will be :class:`PrepareProtocol`.
693
694.. literalinclude:: ../includes/sqlite3/adapter_point_1.py
695
696
697Registering an adapter callable
698"""""""""""""""""""""""""""""""
699
700The other possibility is to create a function that converts the type to the
701string representation and register the function with :meth:`register_adapter`.
702
Georg Brandl116aa622007-08-15 14:28:22 +0000703.. literalinclude:: ../includes/sqlite3/adapter_point_2.py
704
705The :mod:`sqlite3` module has two default adapters for Python's built-in
706:class:`datetime.date` and :class:`datetime.datetime` types. Now let's suppose
707we want to store :class:`datetime.datetime` objects not in ISO representation,
708but as a Unix timestamp.
709
710.. literalinclude:: ../includes/sqlite3/adapter_datetime.py
711
712
713Converting SQLite values to custom Python types
714^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
715
716Writing an adapter lets you send custom Python types to SQLite. But to make it
717really useful we need to make the Python to SQLite to Python roundtrip work.
718
719Enter converters.
720
721Let's go back to the :class:`Point` class. We stored the x and y coordinates
722separated via semicolons as strings in SQLite.
723
724First, we'll define a converter function that accepts the string as a parameter
725and constructs a :class:`Point` object from it.
726
727.. note::
728
729 Converter functions **always** get called with a string, no matter under which
730 data type you sent the value to SQLite.
731
Georg Brandl116aa622007-08-15 14:28:22 +0000732::
733
734 def convert_point(s):
735 x, y = map(float, s.split(";"))
736 return Point(x, y)
737
738Now you need to make the :mod:`sqlite3` module know that what you select from
739the database is actually a point. There are two ways of doing this:
740
741* Implicitly via the declared type
742
743* Explicitly via the column name
744
745Both ways are described in section :ref:`sqlite3-module-contents`, in the entries
746for the constants :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`.
747
748The following example illustrates both approaches.
749
750.. literalinclude:: ../includes/sqlite3/converter_point.py
751
752
753Default adapters and converters
754^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
755
756There are default adapters for the date and datetime types in the datetime
757module. They will be sent as ISO dates/ISO timestamps to SQLite.
758
759The default converters are registered under the name "date" for
760:class:`datetime.date` and under the name "timestamp" for
761:class:`datetime.datetime`.
762
763This way, you can use date/timestamps from Python without any additional
764fiddling in most cases. The format of the adapters is also compatible with the
765experimental SQLite date/time functions.
766
767The following example demonstrates this.
768
769.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py
770
771
772.. _sqlite3-controlling-transactions:
773
774Controlling Transactions
775------------------------
776
777By default, the :mod:`sqlite3` module opens transactions implicitly before a
Georg Brandl48310cd2009-01-03 21:18:54 +0000778Data Modification Language (DML) statement (i.e.
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000779``INSERT``/``UPDATE``/``DELETE``/``REPLACE``), and commits transactions
780implicitly before a non-DML, non-query statement (i. e.
781anything other than ``SELECT`` or the aforementioned).
Georg Brandl116aa622007-08-15 14:28:22 +0000782
783So if you are within a transaction and issue a command like ``CREATE TABLE
784...``, ``VACUUM``, ``PRAGMA``, the :mod:`sqlite3` module will commit implicitly
785before executing that command. There are two reasons for doing that. The first
786is that some of these commands don't work within transactions. The other reason
Georg Brandl8a1e4c42009-05-25 21:13:36 +0000787is that sqlite3 needs to keep track of the transaction state (if a transaction
Georg Brandl116aa622007-08-15 14:28:22 +0000788is active or not).
789
Georg Brandl8a1e4c42009-05-25 21:13:36 +0000790You can control which kind of ``BEGIN`` statements sqlite3 implicitly executes
Georg Brandl116aa622007-08-15 14:28:22 +0000791(or none at all) via the *isolation_level* parameter to the :func:`connect`
792call, or via the :attr:`isolation_level` property of connections.
793
794If you want **autocommit mode**, then set :attr:`isolation_level` to None.
795
796Otherwise leave it at its default, which will result in a plain "BEGIN"
Georg Brandla971c652008-11-07 09:39:56 +0000797statement, or set it to one of SQLite's supported isolation levels: "DEFERRED",
798"IMMEDIATE" or "EXCLUSIVE".
Georg Brandl116aa622007-08-15 14:28:22 +0000799
Georg Brandl116aa622007-08-15 14:28:22 +0000800
801
Georg Brandl8a1e4c42009-05-25 21:13:36 +0000802Using :mod:`sqlite3` efficiently
803--------------------------------
Georg Brandl116aa622007-08-15 14:28:22 +0000804
805
806Using shortcut methods
807^^^^^^^^^^^^^^^^^^^^^^
808
809Using the nonstandard :meth:`execute`, :meth:`executemany` and
810:meth:`executescript` methods of the :class:`Connection` object, your code can
811be written more concisely because you don't have to create the (often
812superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
813objects are created implicitly and these shortcut methods return the cursor
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000814objects. This way, you can execute a ``SELECT`` statement and iterate over it
Georg Brandl116aa622007-08-15 14:28:22 +0000815directly using only a single call on the :class:`Connection` object.
816
817.. literalinclude:: ../includes/sqlite3/shortcut_methods.py
818
819
820Accessing columns by name instead of by index
821^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
822
Georg Brandlc5605df2009-08-13 08:26:44 +0000823One useful feature of the :mod:`sqlite3` module is the built-in
Georg Brandl116aa622007-08-15 14:28:22 +0000824:class:`sqlite3.Row` class designed to be used as a row factory.
825
826Rows wrapped with this class can be accessed both by index (like tuples) and
827case-insensitively by name:
828
829.. literalinclude:: ../includes/sqlite3/rowclass.py
830
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000831
832Using the connection as a context manager
833^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
834
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000835Connection objects can be used as context managers
836that automatically commit or rollback transactions. In the event of an
837exception, the transaction is rolled back; otherwise, the transaction is
838committed:
839
840.. literalinclude:: ../includes/sqlite3/ctx_manager.py
Gerhard Häring5d8cd242010-08-06 06:13:25 +0000841
842
843Common issues
844-------------
845
846Multithreading
847^^^^^^^^^^^^^^
848
849Older SQLite versions had issues with sharing connections between threads.
850That's why the Python module disallows sharing connections and cursors between
851threads. If you still try to do so, you will get an exception at runtime.
852
853The only exception is calling the :meth:`~Connection.interrupt` method, which
854only makes sense to call from a different thread.