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