blob: 43d3ef1d60c01de0119d267050df7f4590491dc6 [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.
Petri Lehtinena15a8d22012-03-01 21:28:00 +02006.. sectionauthor:: Gerhard Häring <gh@ghaering.de>
Georg Brandl8ec7f652007-08-15 14:28:01 +00007
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
Raymond Hettinger81a55c02012-02-01 13:32:45 -080025 import sqlite3
Raymond Hettinger33c66302012-04-17 22:48:06 -040026 conn = sqlite3.connect('example.db')
Georg Brandl8ec7f652007-08-15 14:28:01 +000027
28You can also supply the special name ``:memory:`` to create a database in RAM.
29
30Once you have a :class:`Connection`, you can create a :class:`Cursor` object
Georg Brandl26497d92008-10-08 17:20:20 +000031and call its :meth:`~Cursor.execute` method to perform SQL commands::
Georg Brandl8ec7f652007-08-15 14:28:01 +000032
33 c = conn.cursor()
34
35 # Create table
Raymond Hettinger33c66302012-04-17 22:48:06 -040036 c.execute('''CREATE TABLE stocks
37 (date text, trans text, symbol text, qty real, price real)''')
Georg Brandl8ec7f652007-08-15 14:28:01 +000038
39 # Insert a row of data
Raymond Hettinger33c66302012-04-17 22:48:06 -040040 c.execute("INSERT INTO stocks VALUES ('2006-01-05','BUY','RHAT',100,35.14)")
Georg Brandl8ec7f652007-08-15 14:28:01 +000041
42 # Save (commit) the changes
43 conn.commit()
44
45 # We can also close the cursor if we are done with it
46 c.close()
47
Raymond Hettinger0e15a6e2012-04-17 15:03:20 -040048The data you've saved is persistent and is available in subsequent sessions::
49
50 import sqlite3
Raymond Hettinger33c66302012-04-17 22:48:06 -040051 conn = sqlite3.connect('example.db')
Raymond Hettinger0e15a6e2012-04-17 15:03:20 -040052 c = conn.cursor()
53
Raymond Hettinger33c66302012-04-17 22:48:06 -040054Usually your SQL operations will need to use values from Python variables. You
55shouldn't assemble your query using Python's string operations because doing so
56is insecure; it makes your program vulnerable to an SQL injection attack
57(see http://xkcd.com/327/ for humorous example of what can go wrong).
58
Georg Brandl8ec7f652007-08-15 14:28:01 +000059Instead, use the DB-API's parameter substitution. Put ``?`` as a placeholder
60wherever you want to use a value, and then provide a tuple of values as the
Georg Brandl498a9b32009-05-20 18:31:14 +000061second argument to the cursor's :meth:`~Cursor.execute` method. (Other database
62modules may use a different placeholder, such as ``%s`` or ``:1``.) For
63example::
Georg Brandl8ec7f652007-08-15 14:28:01 +000064
65 # Never do this -- insecure!
Raymond Hettinger33c66302012-04-17 22:48:06 -040066 symbol = 'RHAT'
67 c.execute("SELECT * FROM stocks WHERE symbol = '%s'" % symbol)
Georg Brandl8ec7f652007-08-15 14:28:01 +000068
69 # Do this instead
70 t = (symbol,)
Raymond Hettinger33c66302012-04-17 22:48:06 -040071 c.execute('SELECT * FROM stocks WHERE symbol=?', t)
72 print c.fetchone()
Georg Brandl8ec7f652007-08-15 14:28:01 +000073
Raymond Hettinger33c66302012-04-17 22:48:06 -040074 # Larger example that inserts many records at a time
75 purchases = [('2006-03-28', 'BUY', 'IBM', 1000, 45.00),
76 ('2006-04-05', 'BUY', 'MSFT', 1000, 72.00),
77 ('2006-04-06', 'SELL', 'IBM', 500, 53.00),
78 ]
79 c.executemany('INSERT INTO stocks VALUES (?,?,?,?,?)', purchases)
Georg Brandl8ec7f652007-08-15 14:28:01 +000080
Georg Brandle7a09902007-10-21 12:10:28 +000081To retrieve data after executing a SELECT statement, you can either treat the
Georg Brandl26497d92008-10-08 17:20:20 +000082cursor as an :term:`iterator`, call the cursor's :meth:`~Cursor.fetchone` method to
83retrieve a single matching row, or call :meth:`~Cursor.fetchall` to get a list of the
Georg Brandle7a09902007-10-21 12:10:28 +000084matching rows.
Georg Brandl8ec7f652007-08-15 14:28:01 +000085
86This example uses the iterator form::
87
Raymond Hettinger33c66302012-04-17 22:48:06 -040088 >>> for row in c.execute('SELECT * FROM stocks ORDER BY price'):
89 print row
90
Mark Dickinson6b87f112009-11-24 14:27:02 +000091 (u'2006-01-05', u'BUY', u'RHAT', 100, 35.14)
Georg Brandl8ec7f652007-08-15 14:28:01 +000092 (u'2006-03-28', u'BUY', u'IBM', 1000, 45.0)
93 (u'2006-04-06', u'SELL', u'IBM', 500, 53.0)
Raymond Hettingera0ff91c2012-01-10 09:51:51 +000094 (u'2006-04-05', u'BUY', u'MSFT', 1000, 72.0)
Georg Brandl8ec7f652007-08-15 14:28:01 +000095
96
97.. seealso::
98
Michael Foordabe63312010-03-02 14:22:15 +000099 http://code.google.com/p/pysqlite/
Georg Brandl498a9b32009-05-20 18:31:14 +0000100 The pysqlite web page -- sqlite3 is developed externally under the name
101 "pysqlite".
Georg Brandl8ec7f652007-08-15 14:28:01 +0000102
103 http://www.sqlite.org
Georg Brandl498a9b32009-05-20 18:31:14 +0000104 The SQLite web page; the documentation describes the syntax and the
105 available data types for the supported SQL dialect.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000106
Raymond Hettinger33c66302012-04-17 22:48:06 -0400107 http://www.w3schools.com/sql/
108 Tutorial, reference and examples for learning SQL syntax.
109
Georg Brandl8ec7f652007-08-15 14:28:01 +0000110 :pep:`249` - Database API Specification 2.0
111 PEP written by Marc-André Lemburg.
112
113
114.. _sqlite3-module-contents:
115
116Module functions and constants
117------------------------------
118
119
120.. data:: PARSE_DECLTYPES
121
122 This constant is meant to be used with the *detect_types* parameter of the
123 :func:`connect` function.
124
125 Setting it makes the :mod:`sqlite3` module parse the declared type for each
Gerhard Häringe11c9b32008-05-04 13:42:44 +0000126 column it returns. It will parse out the first word of the declared type,
127 i. e. for "integer primary key", it will parse out "integer", or for
128 "number(10)" it will parse out "number". Then for that column, it will look
129 into the converters dictionary and use the converter function registered for
130 that type there.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000131
132
133.. data:: PARSE_COLNAMES
134
135 This constant is meant to be used with the *detect_types* parameter of the
136 :func:`connect` function.
137
138 Setting this makes the SQLite interface parse the column name for each column it
139 returns. It will look for a string formed [mytype] in there, and then decide
140 that 'mytype' is the type of the column. It will try to find an entry of
141 'mytype' in the converters dictionary and then use the converter function found
Georg Brandl26497d92008-10-08 17:20:20 +0000142 there to return the value. The column name found in :attr:`Cursor.description`
Georg Brandl8ec7f652007-08-15 14:28:01 +0000143 is only the first word of the column name, i. e. if you use something like
144 ``'as "x [datetime]"'`` in your SQL, then we will parse out everything until the
145 first blank for the column name: the column name would simply be "x".
146
147
Georg Brandle85e1ae2010-10-06 09:17:24 +0000148.. function:: connect(database[, timeout, detect_types, isolation_level, check_same_thread, factory, cached_statements])
Georg Brandl8ec7f652007-08-15 14:28:01 +0000149
150 Opens a connection to the SQLite database file *database*. You can use
151 ``":memory:"`` to open a database connection to a database that resides in RAM
152 instead of on disk.
153
154 When a database is accessed by multiple connections, and one of the processes
155 modifies the database, the SQLite database is locked until that transaction is
156 committed. The *timeout* parameter specifies how long the connection should wait
157 for the lock to go away until raising an exception. The default for the timeout
158 parameter is 5.0 (five seconds).
159
160 For the *isolation_level* parameter, please see the
161 :attr:`Connection.isolation_level` property of :class:`Connection` objects.
162
163 SQLite natively supports only the types TEXT, INTEGER, FLOAT, BLOB and NULL. If
164 you want to use other types you must add support for them yourself. The
165 *detect_types* parameter and the using custom **converters** registered with the
166 module-level :func:`register_converter` function allow you to easily do that.
167
168 *detect_types* defaults to 0 (i. e. off, no type detection), you can set it to
169 any combination of :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES` to turn
170 type detection on.
171
172 By default, the :mod:`sqlite3` module uses its :class:`Connection` class for the
173 connect call. You can, however, subclass the :class:`Connection` class and make
174 :func:`connect` use your class instead by providing your class for the *factory*
175 parameter.
176
177 Consult the section :ref:`sqlite3-types` of this manual for details.
178
179 The :mod:`sqlite3` module internally uses a statement cache to avoid SQL parsing
180 overhead. If you want to explicitly set the number of statements that are cached
181 for the connection, you can set the *cached_statements* parameter. The currently
182 implemented default is to cache 100 statements.
183
184
185.. function:: register_converter(typename, callable)
186
187 Registers a callable to convert a bytestring from the database into a custom
188 Python type. The callable will be invoked for all database values that are of
189 the type *typename*. Confer the parameter *detect_types* of the :func:`connect`
190 function for how the type detection works. Note that the case of *typename* and
191 the name of the type in your query must match!
192
193
194.. function:: register_adapter(type, callable)
195
196 Registers a callable to convert the custom Python type *type* into one of
197 SQLite's supported types. The callable *callable* accepts as single parameter
198 the Python value, and must return a value of the following types: int, long,
199 float, str (UTF-8 encoded), unicode or buffer.
200
201
202.. function:: complete_statement(sql)
203
204 Returns :const:`True` if the string *sql* contains one or more complete SQL
205 statements terminated by semicolons. It does not verify that the SQL is
206 syntactically correct, only that there are no unclosed string literals and the
207 statement is terminated by a semicolon.
208
209 This can be used to build a shell for SQLite, as in the following example:
210
211
212 .. literalinclude:: ../includes/sqlite3/complete_statement.py
213
214
215.. function:: enable_callback_tracebacks(flag)
216
217 By default you will not get any tracebacks in user-defined functions,
218 aggregates, converters, authorizer callbacks etc. If you want to debug them, you
219 can call this function with *flag* as True. Afterwards, you will get tracebacks
220 from callbacks on ``sys.stderr``. Use :const:`False` to disable the feature
221 again.
222
223
224.. _sqlite3-connection-objects:
225
226Connection Objects
227------------------
228
Georg Brandl26497d92008-10-08 17:20:20 +0000229.. class:: Connection
230
231 A SQLite database connection has the following attributes and methods:
Georg Brandl8ec7f652007-08-15 14:28:01 +0000232
233.. attribute:: Connection.isolation_level
234
Benjamin Peterson78f98a42008-11-26 17:39:17 +0000235 Get or set the current isolation level. :const:`None` for autocommit mode or
236 one of "DEFERRED", "IMMEDIATE" or "EXCLUSIVE". See section
Georg Brandl8ec7f652007-08-15 14:28:01 +0000237 :ref:`sqlite3-controlling-transactions` for a more detailed explanation.
238
239
240.. method:: Connection.cursor([cursorClass])
241
242 The cursor method accepts a single optional parameter *cursorClass*. If
243 supplied, this must be a custom cursor class that extends
244 :class:`sqlite3.Cursor`.
245
Gerhard Häring41309302008-03-29 01:27:37 +0000246.. method:: Connection.commit()
247
248 This method commits the current transaction. If you don't call this method,
Ezio Melotti1e87da12011-10-19 10:39:35 +0300249 anything you did since the last call to ``commit()`` is not visible from
Gerhard Häring41309302008-03-29 01:27:37 +0000250 other database connections. If you wonder why you don't see the data you've
251 written to the database, please check you didn't forget to call this method.
252
253.. method:: Connection.rollback()
254
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000255 This method rolls back any changes to the database since the last call to
Gerhard Häring41309302008-03-29 01:27:37 +0000256 :meth:`commit`.
257
258.. method:: Connection.close()
259
260 This closes the database connection. Note that this does not automatically
261 call :meth:`commit`. If you just close your database connection without
262 calling :meth:`commit` first, your changes will be lost!
263
Georg Brandl8ec7f652007-08-15 14:28:01 +0000264.. method:: Connection.execute(sql, [parameters])
265
266 This is a nonstandard shortcut that creates an intermediate cursor object by
Georg Brandl26946ec2010-11-26 07:42:15 +0000267 calling the cursor method, then calls the cursor's :meth:`execute
268 <Cursor.execute>` method with the parameters given.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000269
270
271.. method:: Connection.executemany(sql, [parameters])
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:`executemany
275 <Cursor.executemany>` method with the parameters given.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000276
Georg Brandl8ec7f652007-08-15 14:28:01 +0000277.. method:: Connection.executescript(sql_script)
278
279 This is a nonstandard shortcut that creates an intermediate cursor object by
Georg Brandl26946ec2010-11-26 07:42:15 +0000280 calling the cursor method, then calls the cursor's :meth:`executescript
281 <Cursor.executescript>` method with the parameters given.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000282
283
284.. method:: Connection.create_function(name, num_params, func)
285
286 Creates a user-defined function that you can later use from within SQL
287 statements under the function name *name*. *num_params* is the number of
288 parameters the function accepts, and *func* is a Python callable that is called
289 as the SQL function.
290
291 The function can return any of the types supported by SQLite: unicode, str, int,
292 long, float, buffer and None.
293
294 Example:
295
296 .. literalinclude:: ../includes/sqlite3/md5func.py
297
298
299.. method:: Connection.create_aggregate(name, num_params, aggregate_class)
300
301 Creates a user-defined aggregate function.
302
303 The aggregate class must implement a ``step`` method, which accepts the number
304 of parameters *num_params*, and a ``finalize`` method which will return the
305 final result of the aggregate.
306
307 The ``finalize`` method can return any of the types supported by SQLite:
308 unicode, str, int, long, float, buffer and None.
309
310 Example:
311
312 .. literalinclude:: ../includes/sqlite3/mysumaggr.py
313
314
315.. method:: Connection.create_collation(name, callable)
316
317 Creates a collation with the specified *name* and *callable*. The callable will
318 be passed two string arguments. It should return -1 if the first is ordered
319 lower than the second, 0 if they are ordered equal and 1 if the first is ordered
320 higher than the second. Note that this controls sorting (ORDER BY in SQL) so
321 your comparisons don't affect other SQL operations.
322
323 Note that the callable will get its parameters as Python bytestrings, which will
324 normally be encoded in UTF-8.
325
326 The following example shows a custom collation that sorts "the wrong way":
327
328 .. literalinclude:: ../includes/sqlite3/collation_reverse.py
329
330 To remove a collation, call ``create_collation`` with None as callable::
331
332 con.create_collation("reverse", None)
333
334
335.. method:: Connection.interrupt()
336
337 You can call this method from a different thread to abort any queries that might
338 be executing on the connection. The query will then abort and the caller will
339 get an exception.
340
341
342.. method:: Connection.set_authorizer(authorizer_callback)
343
344 This routine registers a callback. The callback is invoked for each attempt to
345 access a column of a table in the database. The callback should return
346 :const:`SQLITE_OK` if access is allowed, :const:`SQLITE_DENY` if the entire SQL
347 statement should be aborted with an error and :const:`SQLITE_IGNORE` if the
348 column should be treated as a NULL value. These constants are available in the
349 :mod:`sqlite3` module.
350
351 The first argument to the callback signifies what kind of operation is to be
352 authorized. The second and third argument will be arguments or :const:`None`
353 depending on the first argument. The 4th argument is the name of the database
354 ("main", "temp", etc.) if applicable. The 5th argument is the name of the
355 inner-most trigger or view that is responsible for the access attempt or
356 :const:`None` if this access attempt is directly from input SQL code.
357
358 Please consult the SQLite documentation about the possible values for the first
359 argument and the meaning of the second and third argument depending on the first
360 one. All necessary constants are available in the :mod:`sqlite3` module.
361
362
Gerhard Häring41309302008-03-29 01:27:37 +0000363.. method:: Connection.set_progress_handler(handler, n)
364
Gerhard Häring41309302008-03-29 01:27:37 +0000365 This routine registers a callback. The callback is invoked for every *n*
366 instructions of the SQLite virtual machine. This is useful if you want to
367 get called from SQLite during long-running operations, for example to update
368 a GUI.
369
370 If you want to clear any previously installed progress handler, call the
371 method with :const:`None` for *handler*.
372
Petri Lehtinena15a8d22012-03-01 21:28:00 +0200373 .. versionadded:: 2.6
374
Gerhard Häring41309302008-03-29 01:27:37 +0000375
Gerhard Häring3bbb6722010-03-05 09:12:37 +0000376.. method:: Connection.enable_load_extension(enabled)
377
Gerhard Häring3bbb6722010-03-05 09:12:37 +0000378 This routine allows/disallows the SQLite engine to load SQLite extensions
379 from shared libraries. SQLite extensions can define new functions,
Georg Brandl26946ec2010-11-26 07:42:15 +0000380 aggregates or whole new virtual table implementations. One well-known
Gerhard Häring3bbb6722010-03-05 09:12:37 +0000381 extension is the fulltext-search extension distributed with SQLite.
382
Petri Lehtinena15a8d22012-03-01 21:28:00 +0200383 Loadable extensions are disabled by default. See [#f1]_.
Gerhard Häring3bbb6722010-03-05 09:12:37 +0000384
385 .. versionadded:: 2.7
386
Petri Lehtinena15a8d22012-03-01 21:28:00 +0200387 .. literalinclude:: ../includes/sqlite3/load_extension.py
388
389.. method:: Connection.load_extension(path)
390
Georg Brandl26946ec2010-11-26 07:42:15 +0000391 This routine loads a SQLite extension from a shared library. You have to
392 enable extension loading with :meth:`enable_load_extension` before you can
393 use this routine.
Gerhard Häring3bbb6722010-03-05 09:12:37 +0000394
Petri Lehtinena15a8d22012-03-01 21:28:00 +0200395 Loadable extensions are disabled by default. See [#f1]_.
396
397 .. versionadded:: 2.7
Senthil Kumaran7bf5ba02011-06-25 20:48:21 -0700398
Georg Brandl8ec7f652007-08-15 14:28:01 +0000399.. attribute:: Connection.row_factory
400
401 You can change this attribute to a callable that accepts the cursor and the
402 original row as a tuple and will return the real result row. This way, you can
403 implement more advanced ways of returning results, such as returning an object
404 that can also access columns by name.
405
406 Example:
407
408 .. literalinclude:: ../includes/sqlite3/row_factory.py
409
410 If returning a tuple doesn't suffice and you want name-based access to
411 columns, you should consider setting :attr:`row_factory` to the
412 highly-optimized :class:`sqlite3.Row` type. :class:`Row` provides both
413 index-based and case-insensitive name-based access to columns with almost no
414 memory overhead. It will probably be better than your own custom
415 dictionary-based approach or even a db_row based solution.
416
Georg Brandlb19be572007-12-29 10:57:00 +0000417 .. XXX what's a db_row-based solution?
Georg Brandl8ec7f652007-08-15 14:28:01 +0000418
419
420.. attribute:: Connection.text_factory
421
Georg Brandl26497d92008-10-08 17:20:20 +0000422 Using this attribute you can control what objects are returned for the ``TEXT``
423 data type. By default, this attribute is set to :class:`unicode` and the
424 :mod:`sqlite3` module will return Unicode objects for ``TEXT``. If you want to
Georg Brandl8ec7f652007-08-15 14:28:01 +0000425 return bytestrings instead, you can set it to :class:`str`.
426
427 For efficiency reasons, there's also a way to return Unicode objects only for
428 non-ASCII data, and bytestrings otherwise. To activate it, set this attribute to
429 :const:`sqlite3.OptimizedUnicode`.
430
431 You can also set it to any other callable that accepts a single bytestring
432 parameter and returns the resulting object.
433
434 See the following example code for illustration:
435
436 .. literalinclude:: ../includes/sqlite3/text_factory.py
437
438
439.. attribute:: Connection.total_changes
440
441 Returns the total number of database rows that have been modified, inserted, or
442 deleted since the database connection was opened.
443
444
Gregory P. Smithb9803422008-03-28 08:32:09 +0000445.. attribute:: Connection.iterdump
446
447 Returns an iterator to dump the database in an SQL text format. Useful when
448 saving an in-memory database for later restoration. This function provides
449 the same capabilities as the :kbd:`.dump` command in the :program:`sqlite3`
450 shell.
451
452 .. versionadded:: 2.6
453
454 Example::
455
456 # Convert file existing_db.db to SQL dump file dump.sql
Benjamin Petersona7b55a32009-02-20 03:31:23 +0000457 import sqlite3, os
Gregory P. Smithb9803422008-03-28 08:32:09 +0000458
459 con = sqlite3.connect('existing_db.db')
Georg Brandlb9bfea72008-11-06 10:19:11 +0000460 with open('dump.sql', 'w') as f:
461 for line in con.iterdump():
462 f.write('%s\n' % line)
Gregory P. Smithb9803422008-03-28 08:32:09 +0000463
464
Georg Brandl8ec7f652007-08-15 14:28:01 +0000465.. _sqlite3-cursor-objects:
466
467Cursor Objects
468--------------
469
Georg Brandl26946ec2010-11-26 07:42:15 +0000470.. class:: Cursor
Georg Brandl8ec7f652007-08-15 14:28:01 +0000471
Georg Brandl26946ec2010-11-26 07:42:15 +0000472 A :class:`Cursor` instance has the following attributes and methods.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000473
474.. method:: Cursor.execute(sql, [parameters])
475
Georg Brandlf558d2e2008-01-19 20:53:07 +0000476 Executes an SQL statement. The SQL statement may be parametrized (i. e.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000477 placeholders instead of SQL literals). The :mod:`sqlite3` module supports two
478 kinds of placeholders: question marks (qmark style) and named placeholders
479 (named style).
480
Petri Lehtinena15a8d22012-03-01 21:28:00 +0200481 Here's an example of both styles:
Georg Brandl8ec7f652007-08-15 14:28:01 +0000482
483 .. literalinclude:: ../includes/sqlite3/execute_1.py
484
Georg Brandl8ec7f652007-08-15 14:28:01 +0000485 :meth:`execute` will only execute a single SQL statement. If you try to execute
486 more than one statement with it, it will raise a Warning. Use
487 :meth:`executescript` if you want to execute multiple SQL statements with one
488 call.
489
490
491.. method:: Cursor.executemany(sql, seq_of_parameters)
492
Georg Brandlf558d2e2008-01-19 20:53:07 +0000493 Executes an SQL command against all parameter sequences or mappings found in
Georg Brandle7a09902007-10-21 12:10:28 +0000494 the sequence *sql*. The :mod:`sqlite3` module also allows using an
495 :term:`iterator` yielding parameters instead of a sequence.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000496
497 .. literalinclude:: ../includes/sqlite3/executemany_1.py
498
Georg Brandlcf3fb252007-10-21 10:52:38 +0000499 Here's a shorter example using a :term:`generator`:
Georg Brandl8ec7f652007-08-15 14:28:01 +0000500
501 .. literalinclude:: ../includes/sqlite3/executemany_2.py
502
503
504.. method:: Cursor.executescript(sql_script)
505
506 This is a nonstandard convenience method for executing multiple SQL statements
Georg Brandl26497d92008-10-08 17:20:20 +0000507 at once. It issues a ``COMMIT`` statement first, then executes the SQL script it
Georg Brandl8ec7f652007-08-15 14:28:01 +0000508 gets as a parameter.
509
510 *sql_script* can be a bytestring or a Unicode string.
511
512 Example:
513
514 .. literalinclude:: ../includes/sqlite3/executescript.py
515
516
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000517.. method:: Cursor.fetchone()
518
Georg Brandlf558d2e2008-01-19 20:53:07 +0000519 Fetches the next row of a query result set, returning a single sequence,
Georg Brandl26497d92008-10-08 17:20:20 +0000520 or :const:`None` when no more data is available.
Georg Brandlf558d2e2008-01-19 20:53:07 +0000521
522
523.. method:: Cursor.fetchmany([size=cursor.arraysize])
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000524
Georg Brandlf558d2e2008-01-19 20:53:07 +0000525 Fetches the next set of rows of a query result, returning a list. An empty
526 list is returned when no more rows are available.
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000527
Georg Brandlf558d2e2008-01-19 20:53:07 +0000528 The number of rows to fetch per call is specified by the *size* parameter.
529 If it is not given, the cursor's arraysize determines the number of rows
530 to be fetched. The method should try to fetch as many rows as indicated by
531 the size parameter. If this is not possible due to the specified number of
532 rows not being available, fewer rows may be returned.
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000533
Georg Brandlf558d2e2008-01-19 20:53:07 +0000534 Note there are performance considerations involved with the *size* parameter.
535 For optimal performance, it is usually best to use the arraysize attribute.
536 If the *size* parameter is used, then it is best for it to retain the same
537 value from one :meth:`fetchmany` call to the next.
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000538
539.. method:: Cursor.fetchall()
Georg Brandlf558d2e2008-01-19 20:53:07 +0000540
541 Fetches all (remaining) rows of a query result, returning a list. Note that
542 the cursor's arraysize attribute can affect the performance of this operation.
543 An empty list is returned when no rows are available.
544
545
Georg Brandl8ec7f652007-08-15 14:28:01 +0000546.. attribute:: Cursor.rowcount
547
548 Although the :class:`Cursor` class of the :mod:`sqlite3` module implements this
549 attribute, the database engine's own support for the determination of "rows
550 affected"/"rows selected" is quirky.
551
Georg Brandl8ec7f652007-08-15 14:28:01 +0000552 For :meth:`executemany` statements, the number of modifications are summed up
553 into :attr:`rowcount`.
554
555 As required by the Python DB API Spec, the :attr:`rowcount` attribute "is -1 in
Georg Brandl26497d92008-10-08 17:20:20 +0000556 case no ``executeXX()`` has been performed on the cursor or the rowcount of the
Petri Lehtinen002b2022012-02-16 21:42:34 +0200557 last operation is not determinable by the interface". This includes ``SELECT``
558 statements because we cannot determine the number of rows a query produced
559 until all rows were fetched.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000560
Petri Lehtinen002b2022012-02-16 21:42:34 +0200561 With SQLite versions before 3.6.5, :attr:`rowcount` is set to 0 if
562 you make a ``DELETE FROM table`` without any condition.
Georg Brandl891f1d32007-08-23 20:40:01 +0000563
Gerhard Häringc15317e2008-03-29 19:11:52 +0000564.. attribute:: Cursor.lastrowid
565
566 This read-only attribute provides the rowid of the last modified row. It is
567 only set if you issued a ``INSERT`` statement using the :meth:`execute`
568 method. For operations other than ``INSERT`` or when :meth:`executemany` is
569 called, :attr:`lastrowid` is set to :const:`None`.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000570
Georg Brandl26497d92008-10-08 17:20:20 +0000571.. attribute:: Cursor.description
572
573 This read-only attribute provides the column names of the last query. To
574 remain compatible with the Python DB API, it returns a 7-tuple for each
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000575 column where the last six items of each tuple are :const:`None`.
576
Georg Brandl26497d92008-10-08 17:20:20 +0000577 It is set for ``SELECT`` statements without any matching rows as well.
578
579.. _sqlite3-row-objects:
580
581Row Objects
582-----------
583
584.. class:: Row
585
586 A :class:`Row` instance serves as a highly optimized
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000587 :attr:`~Connection.row_factory` for :class:`Connection` objects.
Georg Brandl26497d92008-10-08 17:20:20 +0000588 It tries to mimic a tuple in most of its features.
589
590 It supports mapping access by column name and index, iteration,
591 representation, equality testing and :func:`len`.
592
593 If two :class:`Row` objects have exactly the same columns and their
594 members are equal, they compare equal.
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000595
Georg Brandl26497d92008-10-08 17:20:20 +0000596 .. versionchanged:: 2.6
597 Added iteration and equality (hashability).
598
599 .. method:: keys
600
601 This method returns a tuple of column names. Immediately after a query,
602 it is the first member of each tuple in :attr:`Cursor.description`.
603
604 .. versionadded:: 2.6
605
606Let's assume we initialize a table as in the example given above::
607
Senthil Kumarane04d2562011-07-03 10:12:59 -0700608 conn = sqlite3.connect(":memory:")
609 c = conn.cursor()
610 c.execute('''create table stocks
611 (date text, trans text, symbol text,
612 qty real, price real)''')
613 c.execute("""insert into stocks
614 values ('2006-01-05','BUY','RHAT',100,35.14)""")
615 conn.commit()
616 c.close()
Georg Brandl26497d92008-10-08 17:20:20 +0000617
618Now we plug :class:`Row` in::
619
Senthil Kumarane04d2562011-07-03 10:12:59 -0700620 >>> conn.row_factory = sqlite3.Row
621 >>> c = conn.cursor()
622 >>> c.execute('select * from stocks')
623 <sqlite3.Cursor object at 0x7f4e7dd8fa80>
624 >>> r = c.fetchone()
625 >>> type(r)
626 <type 'sqlite3.Row'>
627 >>> r
628 (u'2006-01-05', u'BUY', u'RHAT', 100.0, 35.14)
629 >>> len(r)
630 5
631 >>> r[2]
632 u'RHAT'
633 >>> r.keys()
634 ['date', 'trans', 'symbol', 'qty', 'price']
635 >>> r['qty']
636 100.0
Petri Lehtinena15a8d22012-03-01 21:28:00 +0200637 >>> for member in r:
638 ... print member
Senthil Kumarane04d2562011-07-03 10:12:59 -0700639 ...
640 2006-01-05
641 BUY
642 RHAT
643 100.0
644 35.14
Georg Brandl26497d92008-10-08 17:20:20 +0000645
646
Georg Brandl8ec7f652007-08-15 14:28:01 +0000647.. _sqlite3-types:
648
649SQLite and Python types
650-----------------------
651
652
653Introduction
654^^^^^^^^^^^^
655
Georg Brandl26497d92008-10-08 17:20:20 +0000656SQLite natively supports the following types: ``NULL``, ``INTEGER``,
657``REAL``, ``TEXT``, ``BLOB``.
Georg Brandl8ec7f652007-08-15 14:28:01 +0000658
659The following Python types can thus be sent to SQLite without any problem:
660
Georg Brandl26497d92008-10-08 17:20:20 +0000661+-----------------------------+-------------+
662| Python type | SQLite type |
663+=============================+=============+
664| :const:`None` | ``NULL`` |
665+-----------------------------+-------------+
666| :class:`int` | ``INTEGER`` |
667+-----------------------------+-------------+
668| :class:`long` | ``INTEGER`` |
669+-----------------------------+-------------+
670| :class:`float` | ``REAL`` |
671+-----------------------------+-------------+
672| :class:`str` (UTF8-encoded) | ``TEXT`` |
673+-----------------------------+-------------+
674| :class:`unicode` | ``TEXT`` |
675+-----------------------------+-------------+
676| :class:`buffer` | ``BLOB`` |
677+-----------------------------+-------------+
Georg Brandl8ec7f652007-08-15 14:28:01 +0000678
679This is how SQLite types are converted to Python types by default:
680
Georg Brandl26497d92008-10-08 17:20:20 +0000681+-------------+----------------------------------------------+
682| SQLite type | Python type |
683+=============+==============================================+
684| ``NULL`` | :const:`None` |
685+-------------+----------------------------------------------+
686| ``INTEGER`` | :class:`int` or :class:`long`, |
687| | depending on size |
688+-------------+----------------------------------------------+
689| ``REAL`` | :class:`float` |
690+-------------+----------------------------------------------+
691| ``TEXT`` | depends on :attr:`~Connection.text_factory`, |
692| | :class:`unicode` by default |
693+-------------+----------------------------------------------+
694| ``BLOB`` | :class:`buffer` |
695+-------------+----------------------------------------------+
Georg Brandl8ec7f652007-08-15 14:28:01 +0000696
697The type system of the :mod:`sqlite3` module is extensible in two ways: you can
698store additional Python types in a SQLite database via object adaptation, and
699you can let the :mod:`sqlite3` module convert SQLite types to different Python
700types via converters.
701
702
703Using adapters to store additional Python types in SQLite databases
704^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
705
706As described before, SQLite supports only a limited set of types natively. To
707use other Python types with SQLite, you must **adapt** them to one of the
708sqlite3 module's supported types for SQLite: one of NoneType, int, long, float,
709str, unicode, buffer.
710
711The :mod:`sqlite3` module uses Python object adaptation, as described in
712:pep:`246` for this. The protocol to use is :class:`PrepareProtocol`.
713
714There are two ways to enable the :mod:`sqlite3` module to adapt a custom Python
715type to one of the supported ones.
716
717
718Letting your object adapt itself
719""""""""""""""""""""""""""""""""
720
721This is a good approach if you write the class yourself. Let's suppose you have
722a class like this::
723
724 class Point(object):
725 def __init__(self, x, y):
726 self.x, self.y = x, y
727
728Now you want to store the point in a single SQLite column. First you'll have to
729choose one of the supported types first to be used for representing the point.
730Let's just use str and separate the coordinates using a semicolon. Then you need
731to give your class a method ``__conform__(self, protocol)`` which must return
732the converted value. The parameter *protocol* will be :class:`PrepareProtocol`.
733
734.. literalinclude:: ../includes/sqlite3/adapter_point_1.py
735
736
737Registering an adapter callable
738"""""""""""""""""""""""""""""""
739
740The other possibility is to create a function that converts the type to the
741string representation and register the function with :meth:`register_adapter`.
742
743.. note::
744
Georg Brandla7395032007-10-21 12:15:05 +0000745 The type/class to adapt must be a :term:`new-style class`, i. e. it must have
Georg Brandl8ec7f652007-08-15 14:28:01 +0000746 :class:`object` as one of its bases.
747
748.. literalinclude:: ../includes/sqlite3/adapter_point_2.py
749
750The :mod:`sqlite3` module has two default adapters for Python's built-in
751:class:`datetime.date` and :class:`datetime.datetime` types. Now let's suppose
752we want to store :class:`datetime.datetime` objects not in ISO representation,
753but as a Unix timestamp.
754
755.. literalinclude:: ../includes/sqlite3/adapter_datetime.py
756
757
758Converting SQLite values to custom Python types
759^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
760
761Writing an adapter lets you send custom Python types to SQLite. But to make it
762really useful we need to make the Python to SQLite to Python roundtrip work.
763
764Enter converters.
765
766Let's go back to the :class:`Point` class. We stored the x and y coordinates
767separated via semicolons as strings in SQLite.
768
769First, we'll define a converter function that accepts the string as a parameter
770and constructs a :class:`Point` object from it.
771
772.. note::
773
774 Converter functions **always** get called with a string, no matter under which
775 data type you sent the value to SQLite.
776
Georg Brandl8ec7f652007-08-15 14:28:01 +0000777::
778
779 def convert_point(s):
780 x, y = map(float, s.split(";"))
781 return Point(x, y)
782
783Now you need to make the :mod:`sqlite3` module know that what you select from
784the database is actually a point. There are two ways of doing this:
785
786* Implicitly via the declared type
787
788* Explicitly via the column name
789
790Both ways are described in section :ref:`sqlite3-module-contents`, in the entries
791for the constants :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`.
792
793The following example illustrates both approaches.
794
795.. literalinclude:: ../includes/sqlite3/converter_point.py
796
797
798Default adapters and converters
799^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
800
801There are default adapters for the date and datetime types in the datetime
802module. They will be sent as ISO dates/ISO timestamps to SQLite.
803
804The default converters are registered under the name "date" for
805:class:`datetime.date` and under the name "timestamp" for
806:class:`datetime.datetime`.
807
808This way, you can use date/timestamps from Python without any additional
809fiddling in most cases. The format of the adapters is also compatible with the
810experimental SQLite date/time functions.
811
812The following example demonstrates this.
813
814.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py
815
816
817.. _sqlite3-controlling-transactions:
818
819Controlling Transactions
820------------------------
821
822By default, the :mod:`sqlite3` module opens transactions implicitly before a
Georg Brandlc62ef8b2009-01-03 20:55:06 +0000823Data Modification Language (DML) statement (i.e.
Georg Brandl26497d92008-10-08 17:20:20 +0000824``INSERT``/``UPDATE``/``DELETE``/``REPLACE``), and commits transactions
825implicitly before a non-DML, non-query statement (i. e.
826anything other than ``SELECT`` or the aforementioned).
Georg Brandl8ec7f652007-08-15 14:28:01 +0000827
828So if you are within a transaction and issue a command like ``CREATE TABLE
829...``, ``VACUUM``, ``PRAGMA``, the :mod:`sqlite3` module will commit implicitly
830before executing that command. There are two reasons for doing that. The first
831is that some of these commands don't work within transactions. The other reason
Georg Brandl498a9b32009-05-20 18:31:14 +0000832is that sqlite3 needs to keep track of the transaction state (if a transaction
Georg Brandl8ec7f652007-08-15 14:28:01 +0000833is active or not).
834
Georg Brandl498a9b32009-05-20 18:31:14 +0000835You can control which kind of ``BEGIN`` statements sqlite3 implicitly executes
Georg Brandl8ec7f652007-08-15 14:28:01 +0000836(or none at all) via the *isolation_level* parameter to the :func:`connect`
837call, or via the :attr:`isolation_level` property of connections.
838
839If you want **autocommit mode**, then set :attr:`isolation_level` to None.
840
841Otherwise leave it at its default, which will result in a plain "BEGIN"
Georg Brandlb9bfea72008-11-06 10:19:11 +0000842statement, or set it to one of SQLite's supported isolation levels: "DEFERRED",
843"IMMEDIATE" or "EXCLUSIVE".
Georg Brandl8ec7f652007-08-15 14:28:01 +0000844
Georg Brandl8ec7f652007-08-15 14:28:01 +0000845
846
Georg Brandl498a9b32009-05-20 18:31:14 +0000847Using :mod:`sqlite3` efficiently
848--------------------------------
Georg Brandl8ec7f652007-08-15 14:28:01 +0000849
850
851Using shortcut methods
852^^^^^^^^^^^^^^^^^^^^^^
853
854Using the nonstandard :meth:`execute`, :meth:`executemany` and
855:meth:`executescript` methods of the :class:`Connection` object, your code can
856be written more concisely because you don't have to create the (often
857superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
858objects are created implicitly and these shortcut methods return the cursor
Georg Brandl26497d92008-10-08 17:20:20 +0000859objects. This way, you can execute a ``SELECT`` statement and iterate over it
Georg Brandl8ec7f652007-08-15 14:28:01 +0000860directly using only a single call on the :class:`Connection` object.
861
862.. literalinclude:: ../includes/sqlite3/shortcut_methods.py
863
864
865Accessing columns by name instead of by index
866^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
867
Georg Brandld7d4fd72009-07-26 14:37:28 +0000868One useful feature of the :mod:`sqlite3` module is the built-in
Georg Brandl8ec7f652007-08-15 14:28:01 +0000869:class:`sqlite3.Row` class designed to be used as a row factory.
870
871Rows wrapped with this class can be accessed both by index (like tuples) and
872case-insensitively by name:
873
874.. literalinclude:: ../includes/sqlite3/rowclass.py
875
Gerhard Häring41309302008-03-29 01:27:37 +0000876
877Using the connection as a context manager
878^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
879
880.. versionadded:: 2.6
881
882Connection objects can be used as context managers
883that automatically commit or rollback transactions. In the event of an
884exception, the transaction is rolled back; otherwise, the transaction is
885committed:
886
887.. literalinclude:: ../includes/sqlite3/ctx_manager.py
Gerhard Häring5f5c15f2010-08-06 06:14:12 +0000888
889
890Common issues
891-------------
892
893Multithreading
894^^^^^^^^^^^^^^
895
896Older SQLite versions had issues with sharing connections between threads.
897That's why the Python module disallows sharing connections and cursors between
898threads. If you still try to do so, you will get an exception at runtime.
899
900The only exception is calling the :meth:`~Connection.interrupt` method, which
901only makes sense to call from a different thread.
Senthil Kumaran7bf5ba02011-06-25 20:48:21 -0700902
903.. rubric:: Footnotes
904
905.. [#f1] The sqlite3 module is not built with loadable extension support by
Senthil Kumarane04d2562011-07-03 10:12:59 -0700906 default, because some platforms (notably Mac OS X) have SQLite libraries
907 which are compiled without this feature. To get loadable extension support,
908 you must modify setup.py and remove the line that sets
909 SQLITE_OMIT_LOAD_EXTENSION.
Senthil Kumaran7bf5ba02011-06-25 20:48:21 -0700910