blob: 529dc9449ef7fafb937e07ef723cbbbed783a5cd [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.
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +02006.. sectionauthor:: Gerhard Häring <gh@ghaering.de>
Georg Brandl116aa622007-08-15 14:28:22 +00007
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
Petri Lehtinen9f74c6c2013-02-23 19:26:56 +010021:file:`example.db` file::
Georg Brandl116aa622007-08-15 14:28:22 +000022
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +020023 import sqlite3
Petri Lehtinen9f74c6c2013-02-23 19:26:56 +010024 conn = sqlite3.connect('example.db')
Georg Brandl116aa622007-08-15 14:28:22 +000025
26You can also supply the special name ``:memory:`` to create a database in RAM.
27
28Once you have a :class:`Connection`, you can create a :class:`Cursor` object
Benjamin Petersonf10a79a2008-10-11 00:49:57 +000029and call its :meth:`~Cursor.execute` method to perform SQL commands::
Georg Brandl116aa622007-08-15 14:28:22 +000030
31 c = conn.cursor()
32
33 # Create table
34 c.execute('''create table stocks
35 (date text, trans text, symbol text,
36 qty real, price real)''')
37
38 # Insert a row of data
39 c.execute("""insert into stocks
40 values ('2006-01-05','BUY','RHAT',100,35.14)""")
41
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
48Usually your SQL operations will need to use values from Python variables. You
49shouldn't assemble your query using Python's string operations because doing so
50is insecure; it makes your program vulnerable to an SQL injection attack.
51
52Instead, use the DB-API's parameter substitution. Put ``?`` as a placeholder
53wherever you want to use a value, and then provide a tuple of values as the
Georg Brandl8a1e4c42009-05-25 21:13:36 +000054second argument to the cursor's :meth:`~Cursor.execute` method. (Other database
55modules may use a different placeholder, such as ``%s`` or ``:1``.) For
56example::
Georg Brandl116aa622007-08-15 14:28:22 +000057
58 # Never do this -- insecure!
59 symbol = 'IBM'
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +020060 c.execute("select * from stocks where symbol = '%s'" % symbol)
Georg Brandl116aa622007-08-15 14:28:22 +000061
62 # Do this instead
R David Murrayf6bd1b02012-08-20 14:14:18 -040063 t = ('IBM',)
Georg Brandl116aa622007-08-15 14:28:22 +000064 c.execute('select * from stocks where symbol=?', t)
65
66 # Larger example
Georg Brandla971c652008-11-07 09:39:56 +000067 for t in [('2006-03-28', 'BUY', 'IBM', 1000, 45.00),
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +020068 ('2006-04-05', 'BUY', 'MSFT', 1000, 72.00),
Georg Brandl116aa622007-08-15 14:28:22 +000069 ('2006-04-06', 'SELL', 'IBM', 500, 53.00),
Georg Brandla971c652008-11-07 09:39:56 +000070 ]:
Georg Brandl116aa622007-08-15 14:28:22 +000071 c.execute('insert into stocks values (?,?,?,?,?)', t)
72
Georg Brandl9afde1c2007-11-01 20:32:30 +000073To retrieve data after executing a SELECT statement, you can either treat the
Benjamin Petersonf10a79a2008-10-11 00:49:57 +000074cursor as an :term:`iterator`, call the cursor's :meth:`~Cursor.fetchone` method to
75retrieve a single matching row, or call :meth:`~Cursor.fetchall` to get a list of the
Georg Brandl9afde1c2007-11-01 20:32:30 +000076matching rows.
Georg Brandl116aa622007-08-15 14:28:22 +000077
78This example uses the iterator form::
79
80 >>> c = conn.cursor()
81 >>> c.execute('select * from stocks order by price')
82 >>> for row in c:
Ezio Melottib5845052009-09-13 05:49:25 +000083 ... print(row)
Georg Brandl116aa622007-08-15 14:28:22 +000084 ...
Ezio Melottib5845052009-09-13 05:49:25 +000085 ('2006-01-05', 'BUY', 'RHAT', 100, 35.14)
86 ('2006-03-28', 'BUY', 'IBM', 1000, 45.0)
87 ('2006-04-06', 'SELL', 'IBM', 500, 53.0)
88 ('2006-04-05', 'BUY', 'MSOFT', 1000, 72.0)
Georg Brandl116aa622007-08-15 14:28:22 +000089 >>>
90
91
92.. seealso::
93
Benjamin Peterson2614cda2010-03-21 22:36:19 +000094 http://code.google.com/p/pysqlite/
Georg Brandl8a1e4c42009-05-25 21:13:36 +000095 The pysqlite web page -- sqlite3 is developed externally under the name
96 "pysqlite".
Georg Brandl116aa622007-08-15 14:28:22 +000097
98 http://www.sqlite.org
Georg Brandl8a1e4c42009-05-25 21:13:36 +000099 The SQLite web page; the documentation describes the syntax and the
100 available data types for the supported SQL dialect.
Georg Brandl116aa622007-08-15 14:28:22 +0000101
102 :pep:`249` - Database API Specification 2.0
103 PEP written by Marc-André Lemburg.
104
105
106.. _sqlite3-module-contents:
107
108Module functions and constants
109------------------------------
110
111
R David Murray3f7beb92013-01-10 20:18:21 -0500112.. data:: version
113
114 The version number of this module, as a string. This is not the version of
115 the SQLite library.
116
117
118.. data:: version_info
119
120 The version number of this module, as a tuple of integers. This is not the
121 version of the SQLite library.
122
123
124.. data:: sqlite_version
125
126 The version number of the run-time SQLite library, as a string.
127
128
129.. data:: sqlite_version_info
130
131 The version number of the run-time SQLite library, as a tuple of integers.
132
133
Georg Brandl116aa622007-08-15 14:28:22 +0000134.. data:: PARSE_DECLTYPES
135
136 This constant is meant to be used with the *detect_types* parameter of the
137 :func:`connect` function.
138
139 Setting it makes the :mod:`sqlite3` module parse the declared type for each
Christian Heimes81ee3ef2008-05-04 22:42:01 +0000140 column it returns. It will parse out the first word of the declared type,
141 i. e. for "integer primary key", it will parse out "integer", or for
142 "number(10)" it will parse out "number". Then for that column, it will look
143 into the converters dictionary and use the converter function registered for
144 that type there.
Georg Brandl116aa622007-08-15 14:28:22 +0000145
146
147.. data:: PARSE_COLNAMES
148
149 This constant is meant to be used with the *detect_types* parameter of the
150 :func:`connect` function.
151
152 Setting this makes the SQLite interface parse the column name for each column it
153 returns. It will look for a string formed [mytype] in there, and then decide
154 that 'mytype' is the type of the column. It will try to find an entry of
155 'mytype' in the converters dictionary and then use the converter function found
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000156 there to return the value. The column name found in :attr:`Cursor.description`
Georg Brandl116aa622007-08-15 14:28:22 +0000157 is only the first word of the column name, i. e. if you use something like
158 ``'as "x [datetime]"'`` in your SQL, then we will parse out everything until the
159 first blank for the column name: the column name would simply be "x".
160
161
Antoine Pitrou902fc8b2013-02-10 00:02:44 +0100162.. function:: connect(database[, timeout, detect_types, isolation_level, check_same_thread, factory, cached_statements, uri])
Georg Brandl116aa622007-08-15 14:28:22 +0000163
164 Opens a connection to the SQLite database file *database*. You can use
165 ``":memory:"`` to open a database connection to a database that resides in RAM
166 instead of on disk.
167
168 When a database is accessed by multiple connections, and one of the processes
169 modifies the database, the SQLite database is locked until that transaction is
170 committed. The *timeout* parameter specifies how long the connection should wait
171 for the lock to go away until raising an exception. The default for the timeout
172 parameter is 5.0 (five seconds).
173
174 For the *isolation_level* parameter, please see the
175 :attr:`Connection.isolation_level` property of :class:`Connection` objects.
176
177 SQLite natively supports only the types TEXT, INTEGER, FLOAT, BLOB and NULL. If
178 you want to use other types you must add support for them yourself. The
179 *detect_types* parameter and the using custom **converters** registered with the
180 module-level :func:`register_converter` function allow you to easily do that.
181
182 *detect_types* defaults to 0 (i. e. off, no type detection), you can set it to
183 any combination of :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES` to turn
184 type detection on.
185
186 By default, the :mod:`sqlite3` module uses its :class:`Connection` class for the
187 connect call. You can, however, subclass the :class:`Connection` class and make
188 :func:`connect` use your class instead by providing your class for the *factory*
189 parameter.
190
191 Consult the section :ref:`sqlite3-types` of this manual for details.
192
193 The :mod:`sqlite3` module internally uses a statement cache to avoid SQL parsing
194 overhead. If you want to explicitly set the number of statements that are cached
195 for the connection, you can set the *cached_statements* parameter. The currently
196 implemented default is to cache 100 statements.
197
Antoine Pitrou902fc8b2013-02-10 00:02:44 +0100198 If *uri* is true, *database* is interpreted as a URI. This allows you
199 to specify options. For example, to open a database in read-only mode
200 you can use::
201
202 db = sqlite3.connect('file:path/to/database?mode=ro', uri=True)
203
204 More information about this feature, including a list of recognized options, can
205 be found in the `SQLite URI documentation <http://www.sqlite.org/uri.html>`_.
206
207 .. versionchanged:: 3.4
208 Added the *uri* parameter.
209
Georg Brandl116aa622007-08-15 14:28:22 +0000210
211.. function:: register_converter(typename, callable)
212
213 Registers a callable to convert a bytestring from the database into a custom
214 Python type. The callable will be invoked for all database values that are of
215 the type *typename*. Confer the parameter *detect_types* of the :func:`connect`
216 function for how the type detection works. Note that the case of *typename* and
217 the name of the type in your query must match!
218
219
220.. function:: register_adapter(type, callable)
221
222 Registers a callable to convert the custom Python type *type* into one of
223 SQLite's supported types. The callable *callable* accepts as single parameter
Georg Brandl5c106642007-11-29 17:41:05 +0000224 the Python value, and must return a value of the following types: int,
Antoine Pitrouf06917e2010-02-02 23:00:29 +0000225 float, str or bytes.
Georg Brandl116aa622007-08-15 14:28:22 +0000226
227
228.. function:: complete_statement(sql)
229
230 Returns :const:`True` if the string *sql* contains one or more complete SQL
231 statements terminated by semicolons. It does not verify that the SQL is
232 syntactically correct, only that there are no unclosed string literals and the
233 statement is terminated by a semicolon.
234
235 This can be used to build a shell for SQLite, as in the following example:
236
237
238 .. literalinclude:: ../includes/sqlite3/complete_statement.py
239
240
241.. function:: enable_callback_tracebacks(flag)
242
243 By default you will not get any tracebacks in user-defined functions,
244 aggregates, converters, authorizer callbacks etc. If you want to debug them, you
245 can call this function with *flag* as True. Afterwards, you will get tracebacks
246 from callbacks on ``sys.stderr``. Use :const:`False` to disable the feature
247 again.
248
249
250.. _sqlite3-connection-objects:
251
252Connection Objects
253------------------
254
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000255.. class:: Connection
256
257 A SQLite database connection has the following attributes and methods:
Georg Brandl116aa622007-08-15 14:28:22 +0000258
R David Murray6db23352012-09-30 20:44:43 -0400259 .. attribute:: isolation_level
Georg Brandl116aa622007-08-15 14:28:22 +0000260
R David Murray6db23352012-09-30 20:44:43 -0400261 Get or set the current isolation level. :const:`None` for autocommit mode or
262 one of "DEFERRED", "IMMEDIATE" or "EXCLUSIVE". See section
263 :ref:`sqlite3-controlling-transactions` for a more detailed explanation.
Georg Brandl116aa622007-08-15 14:28:22 +0000264
R David Murray6db23352012-09-30 20:44:43 -0400265 .. attribute:: in_transaction
R. David Murrayd35251d2010-06-01 01:32:12 +0000266
R David Murray6db23352012-09-30 20:44:43 -0400267 :const:`True` if a transaction is active (there are uncommitted changes),
268 :const:`False` otherwise. Read-only attribute.
R. David Murrayd35251d2010-06-01 01:32:12 +0000269
R David Murray6db23352012-09-30 20:44:43 -0400270 .. versionadded:: 3.2
Georg Brandl116aa622007-08-15 14:28:22 +0000271
R David Murray6db23352012-09-30 20:44:43 -0400272 .. method:: cursor([cursorClass])
Georg Brandl116aa622007-08-15 14:28:22 +0000273
R David Murray6db23352012-09-30 20:44:43 -0400274 The cursor method accepts a single optional parameter *cursorClass*. If
275 supplied, this must be a custom cursor class that extends
276 :class:`sqlite3.Cursor`.
Georg Brandl116aa622007-08-15 14:28:22 +0000277
R David Murray6db23352012-09-30 20:44:43 -0400278 .. method:: commit()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000279
R David Murray6db23352012-09-30 20:44:43 -0400280 This method commits the current transaction. If you don't call this method,
281 anything you did since the last call to ``commit()`` is not visible from
282 other database connections. If you wonder why you don't see the data you've
283 written to the database, please check you didn't forget to call this method.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000284
R David Murray6db23352012-09-30 20:44:43 -0400285 .. method:: rollback()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000286
R David Murray6db23352012-09-30 20:44:43 -0400287 This method rolls back any changes to the database since the last call to
288 :meth:`commit`.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000289
R David Murray6db23352012-09-30 20:44:43 -0400290 .. method:: close()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000291
R David Murray6db23352012-09-30 20:44:43 -0400292 This closes the database connection. Note that this does not automatically
293 call :meth:`commit`. If you just close your database connection without
294 calling :meth:`commit` first, your changes will be lost!
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000295
R David Murray6db23352012-09-30 20:44:43 -0400296 .. method:: execute(sql, [parameters])
Georg Brandl116aa622007-08-15 14:28:22 +0000297
R David Murray6db23352012-09-30 20:44:43 -0400298 This is a nonstandard shortcut that creates an intermediate cursor object by
299 calling the cursor method, then calls the cursor's :meth:`execute
300 <Cursor.execute>` method with the parameters given.
Georg Brandl116aa622007-08-15 14:28:22 +0000301
302
R David Murray6db23352012-09-30 20:44:43 -0400303 .. method:: executemany(sql, [parameters])
Georg Brandl116aa622007-08-15 14:28:22 +0000304
R David Murray6db23352012-09-30 20:44:43 -0400305 This is a nonstandard shortcut that creates an intermediate cursor object by
306 calling the cursor method, then calls the cursor's :meth:`executemany
307 <Cursor.executemany>` method with the parameters given.
Georg Brandl116aa622007-08-15 14:28:22 +0000308
R David Murray6db23352012-09-30 20:44:43 -0400309 .. method:: executescript(sql_script)
Georg Brandl116aa622007-08-15 14:28:22 +0000310
R David Murray6db23352012-09-30 20:44:43 -0400311 This is a nonstandard shortcut that creates an intermediate cursor object by
312 calling the cursor method, then calls the cursor's :meth:`executescript
313 <Cursor.executescript>` method with the parameters given.
Georg Brandl116aa622007-08-15 14:28:22 +0000314
315
R David Murray6db23352012-09-30 20:44:43 -0400316 .. method:: create_function(name, num_params, func)
Georg Brandl116aa622007-08-15 14:28:22 +0000317
R David Murray6db23352012-09-30 20:44:43 -0400318 Creates a user-defined function that you can later use from within SQL
319 statements under the function name *name*. *num_params* is the number of
320 parameters the function accepts, and *func* is a Python callable that is called
321 as the SQL function.
Georg Brandl116aa622007-08-15 14:28:22 +0000322
R David Murray6db23352012-09-30 20:44:43 -0400323 The function can return any of the types supported by SQLite: bytes, str, int,
324 float and None.
Georg Brandl116aa622007-08-15 14:28:22 +0000325
R David Murray6db23352012-09-30 20:44:43 -0400326 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000327
R David Murray6db23352012-09-30 20:44:43 -0400328 .. literalinclude:: ../includes/sqlite3/md5func.py
Georg Brandl116aa622007-08-15 14:28:22 +0000329
330
R David Murray6db23352012-09-30 20:44:43 -0400331 .. method:: create_aggregate(name, num_params, aggregate_class)
Georg Brandl116aa622007-08-15 14:28:22 +0000332
R David Murray6db23352012-09-30 20:44:43 -0400333 Creates a user-defined aggregate function.
Georg Brandl116aa622007-08-15 14:28:22 +0000334
R David Murray6db23352012-09-30 20:44:43 -0400335 The aggregate class must implement a ``step`` method, which accepts the number
336 of parameters *num_params*, and a ``finalize`` method which will return the
337 final result of the aggregate.
Georg Brandl116aa622007-08-15 14:28:22 +0000338
R David Murray6db23352012-09-30 20:44:43 -0400339 The ``finalize`` method can return any of the types supported by SQLite:
340 bytes, str, int, float and None.
Georg Brandl116aa622007-08-15 14:28:22 +0000341
R David Murray6db23352012-09-30 20:44:43 -0400342 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000343
R David Murray6db23352012-09-30 20:44:43 -0400344 .. literalinclude:: ../includes/sqlite3/mysumaggr.py
Georg Brandl116aa622007-08-15 14:28:22 +0000345
346
R David Murray6db23352012-09-30 20:44:43 -0400347 .. method:: create_collation(name, callable)
Georg Brandl116aa622007-08-15 14:28:22 +0000348
R David Murray6db23352012-09-30 20:44:43 -0400349 Creates a collation with the specified *name* and *callable*. The callable will
350 be passed two string arguments. It should return -1 if the first is ordered
351 lower than the second, 0 if they are ordered equal and 1 if the first is ordered
352 higher than the second. Note that this controls sorting (ORDER BY in SQL) so
353 your comparisons don't affect other SQL operations.
Georg Brandl116aa622007-08-15 14:28:22 +0000354
R David Murray6db23352012-09-30 20:44:43 -0400355 Note that the callable will get its parameters as Python bytestrings, which will
356 normally be encoded in UTF-8.
Georg Brandl116aa622007-08-15 14:28:22 +0000357
R David Murray6db23352012-09-30 20:44:43 -0400358 The following example shows a custom collation that sorts "the wrong way":
Georg Brandl116aa622007-08-15 14:28:22 +0000359
R David Murray6db23352012-09-30 20:44:43 -0400360 .. literalinclude:: ../includes/sqlite3/collation_reverse.py
Georg Brandl116aa622007-08-15 14:28:22 +0000361
R David Murray6db23352012-09-30 20:44:43 -0400362 To remove a collation, call ``create_collation`` with None as callable::
Georg Brandl116aa622007-08-15 14:28:22 +0000363
R David Murray6db23352012-09-30 20:44:43 -0400364 con.create_collation("reverse", None)
Georg Brandl116aa622007-08-15 14:28:22 +0000365
366
R David Murray6db23352012-09-30 20:44:43 -0400367 .. method:: interrupt()
Georg Brandl116aa622007-08-15 14:28:22 +0000368
R David Murray6db23352012-09-30 20:44:43 -0400369 You can call this method from a different thread to abort any queries that might
370 be executing on the connection. The query will then abort and the caller will
371 get an exception.
Georg Brandl116aa622007-08-15 14:28:22 +0000372
373
R David Murray6db23352012-09-30 20:44:43 -0400374 .. method:: set_authorizer(authorizer_callback)
Georg Brandl116aa622007-08-15 14:28:22 +0000375
R David Murray6db23352012-09-30 20:44:43 -0400376 This routine registers a callback. The callback is invoked for each attempt to
377 access a column of a table in the database. The callback should return
378 :const:`SQLITE_OK` if access is allowed, :const:`SQLITE_DENY` if the entire SQL
379 statement should be aborted with an error and :const:`SQLITE_IGNORE` if the
380 column should be treated as a NULL value. These constants are available in the
381 :mod:`sqlite3` module.
Georg Brandl116aa622007-08-15 14:28:22 +0000382
R David Murray6db23352012-09-30 20:44:43 -0400383 The first argument to the callback signifies what kind of operation is to be
384 authorized. The second and third argument will be arguments or :const:`None`
385 depending on the first argument. The 4th argument is the name of the database
386 ("main", "temp", etc.) if applicable. The 5th argument is the name of the
387 inner-most trigger or view that is responsible for the access attempt or
388 :const:`None` if this access attempt is directly from input SQL code.
Georg Brandl116aa622007-08-15 14:28:22 +0000389
R David Murray6db23352012-09-30 20:44:43 -0400390 Please consult the SQLite documentation about the possible values for the first
391 argument and the meaning of the second and third argument depending on the first
392 one. All necessary constants are available in the :mod:`sqlite3` module.
Georg Brandl116aa622007-08-15 14:28:22 +0000393
Georg Brandl116aa622007-08-15 14:28:22 +0000394
R David Murray6db23352012-09-30 20:44:43 -0400395 .. method:: set_progress_handler(handler, n)
Georg Brandl116aa622007-08-15 14:28:22 +0000396
R David Murray6db23352012-09-30 20:44:43 -0400397 This routine registers a callback. The callback is invoked for every *n*
398 instructions of the SQLite virtual machine. This is useful if you want to
399 get called from SQLite during long-running operations, for example to update
400 a GUI.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000401
R David Murray6db23352012-09-30 20:44:43 -0400402 If you want to clear any previously installed progress handler, call the
403 method with :const:`None` for *handler*.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000404
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000405
R David Murray842ca5f2012-09-30 20:49:19 -0400406 .. method:: set_trace_callback(trace_callback)
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000407
R David Murray842ca5f2012-09-30 20:49:19 -0400408 Registers *trace_callback* to be called for each SQL statement that is
409 actually executed by the SQLite backend.
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200410
R David Murray842ca5f2012-09-30 20:49:19 -0400411 The only argument passed to the callback is the statement (as string) that
412 is being executed. The return value of the callback is ignored. Note that
413 the backend does not only run statements passed to the :meth:`Cursor.execute`
414 methods. Other sources include the transaction management of the Python
415 module and the execution of triggers defined in the current database.
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200416
R David Murray842ca5f2012-09-30 20:49:19 -0400417 Passing :const:`None` as *trace_callback* will disable the trace callback.
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200418
R David Murray842ca5f2012-09-30 20:49:19 -0400419 .. versionadded:: 3.3
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200420
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200421
R David Murray6db23352012-09-30 20:44:43 -0400422 .. method:: enable_load_extension(enabled)
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200423
R David Murray6db23352012-09-30 20:44:43 -0400424 This routine allows/disallows the SQLite engine to load SQLite extensions
425 from shared libraries. SQLite extensions can define new functions,
426 aggregates or whole new virtual table implementations. One well-known
427 extension is the fulltext-search extension distributed with SQLite.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000428
R David Murray6db23352012-09-30 20:44:43 -0400429 Loadable extensions are disabled by default. See [#f1]_.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000430
R David Murray6db23352012-09-30 20:44:43 -0400431 .. versionadded:: 3.2
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +0200432
R David Murray6db23352012-09-30 20:44:43 -0400433 .. literalinclude:: ../includes/sqlite3/load_extension.py
Georg Brandl67b21b72010-08-17 15:07:14 +0000434
R David Murray6db23352012-09-30 20:44:43 -0400435 .. method:: load_extension(path)
Gerhard Häringf9cee222010-03-05 15:20:03 +0000436
R David Murray6db23352012-09-30 20:44:43 -0400437 This routine loads a SQLite extension from a shared library. You have to
438 enable extension loading with :meth:`enable_load_extension` before you can
439 use this routine.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000440
R David Murray6db23352012-09-30 20:44:43 -0400441 Loadable extensions are disabled by default. See [#f1]_.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000442
R David Murray6db23352012-09-30 20:44:43 -0400443 .. versionadded:: 3.2
Gerhard Häringe0941c52010-10-03 21:47:06 +0000444
R David Murray6db23352012-09-30 20:44:43 -0400445 .. attribute:: row_factory
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +0200446
R David Murray6db23352012-09-30 20:44:43 -0400447 You can change this attribute to a callable that accepts the cursor and the
448 original row as a tuple and will return the real result row. This way, you can
449 implement more advanced ways of returning results, such as returning an object
450 that can also access columns by name.
Georg Brandl116aa622007-08-15 14:28:22 +0000451
R David Murray6db23352012-09-30 20:44:43 -0400452 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000453
R David Murray6db23352012-09-30 20:44:43 -0400454 .. literalinclude:: ../includes/sqlite3/row_factory.py
Georg Brandl116aa622007-08-15 14:28:22 +0000455
R David Murray6db23352012-09-30 20:44:43 -0400456 If returning a tuple doesn't suffice and you want name-based access to
457 columns, you should consider setting :attr:`row_factory` to the
458 highly-optimized :class:`sqlite3.Row` type. :class:`Row` provides both
459 index-based and case-insensitive name-based access to columns with almost no
460 memory overhead. It will probably be better than your own custom
461 dictionary-based approach or even a db_row based solution.
Georg Brandl116aa622007-08-15 14:28:22 +0000462
R David Murray6db23352012-09-30 20:44:43 -0400463 .. XXX what's a db_row-based solution?
Georg Brandl116aa622007-08-15 14:28:22 +0000464
Georg Brandl116aa622007-08-15 14:28:22 +0000465
R David Murray6db23352012-09-30 20:44:43 -0400466 .. attribute:: text_factory
Georg Brandl116aa622007-08-15 14:28:22 +0000467
R David Murray6db23352012-09-30 20:44:43 -0400468 Using this attribute you can control what objects are returned for the ``TEXT``
469 data type. By default, this attribute is set to :class:`str` and the
470 :mod:`sqlite3` module will return Unicode objects for ``TEXT``. If you want to
471 return bytestrings instead, you can set it to :class:`bytes`.
Georg Brandl116aa622007-08-15 14:28:22 +0000472
R David Murray6db23352012-09-30 20:44:43 -0400473 For efficiency reasons, there's also a way to return :class:`str` objects
474 only for non-ASCII data, and :class:`bytes` otherwise. To activate it, set
475 this attribute to :const:`sqlite3.OptimizedUnicode`.
Georg Brandl116aa622007-08-15 14:28:22 +0000476
R David Murray6db23352012-09-30 20:44:43 -0400477 You can also set it to any other callable that accepts a single bytestring
478 parameter and returns the resulting object.
Georg Brandl116aa622007-08-15 14:28:22 +0000479
R David Murray6db23352012-09-30 20:44:43 -0400480 See the following example code for illustration:
Georg Brandl116aa622007-08-15 14:28:22 +0000481
R David Murray6db23352012-09-30 20:44:43 -0400482 .. literalinclude:: ../includes/sqlite3/text_factory.py
Georg Brandl116aa622007-08-15 14:28:22 +0000483
484
R David Murray6db23352012-09-30 20:44:43 -0400485 .. attribute:: total_changes
Georg Brandl116aa622007-08-15 14:28:22 +0000486
R David Murray6db23352012-09-30 20:44:43 -0400487 Returns the total number of database rows that have been modified, inserted, or
488 deleted since the database connection was opened.
Georg Brandl116aa622007-08-15 14:28:22 +0000489
490
R David Murray6db23352012-09-30 20:44:43 -0400491 .. attribute:: iterdump
Christian Heimesbbe741d2008-03-28 10:53:29 +0000492
R David Murray6db23352012-09-30 20:44:43 -0400493 Returns an iterator to dump the database in an SQL text format. Useful when
494 saving an in-memory database for later restoration. This function provides
495 the same capabilities as the :kbd:`.dump` command in the :program:`sqlite3`
496 shell.
Christian Heimesbbe741d2008-03-28 10:53:29 +0000497
R David Murray6db23352012-09-30 20:44:43 -0400498 Example::
Christian Heimesbbe741d2008-03-28 10:53:29 +0000499
R David Murray6db23352012-09-30 20:44:43 -0400500 # Convert file existing_db.db to SQL dump file dump.sql
501 import sqlite3, os
Christian Heimesbbe741d2008-03-28 10:53:29 +0000502
R David Murray6db23352012-09-30 20:44:43 -0400503 con = sqlite3.connect('existing_db.db')
504 with open('dump.sql', 'w') as f:
505 for line in con.iterdump():
506 f.write('%s\n' % line)
Christian Heimesbbe741d2008-03-28 10:53:29 +0000507
508
Georg Brandl116aa622007-08-15 14:28:22 +0000509.. _sqlite3-cursor-objects:
510
511Cursor Objects
512--------------
513
Georg Brandl96115fb22010-10-17 09:33:24 +0000514.. class:: Cursor
Georg Brandl116aa622007-08-15 14:28:22 +0000515
Georg Brandl96115fb22010-10-17 09:33:24 +0000516 A :class:`Cursor` instance has the following attributes and methods.
Georg Brandl116aa622007-08-15 14:28:22 +0000517
R David Murray6db23352012-09-30 20:44:43 -0400518 .. method:: execute(sql, [parameters])
Georg Brandl116aa622007-08-15 14:28:22 +0000519
R David Murray6db23352012-09-30 20:44:43 -0400520 Executes an SQL statement. The SQL statement may be parametrized (i. e.
521 placeholders instead of SQL literals). The :mod:`sqlite3` module supports two
522 kinds of placeholders: question marks (qmark style) and named placeholders
523 (named style).
Georg Brandl116aa622007-08-15 14:28:22 +0000524
R David Murray6db23352012-09-30 20:44:43 -0400525 Here's an example of both styles:
Georg Brandl116aa622007-08-15 14:28:22 +0000526
R David Murray6db23352012-09-30 20:44:43 -0400527 .. literalinclude:: ../includes/sqlite3/execute_1.py
Georg Brandl116aa622007-08-15 14:28:22 +0000528
R David Murray6db23352012-09-30 20:44:43 -0400529 :meth:`execute` will only execute a single SQL statement. If you try to execute
530 more than one statement with it, it will raise a Warning. Use
531 :meth:`executescript` if you want to execute multiple SQL statements with one
532 call.
Georg Brandl116aa622007-08-15 14:28:22 +0000533
534
R David Murray6db23352012-09-30 20:44:43 -0400535 .. method:: executemany(sql, seq_of_parameters)
Georg Brandl116aa622007-08-15 14:28:22 +0000536
R David Murray6db23352012-09-30 20:44:43 -0400537 Executes an SQL command against all parameter sequences or mappings found in
538 the sequence *sql*. The :mod:`sqlite3` module also allows using an
539 :term:`iterator` yielding parameters instead of a sequence.
Georg Brandl116aa622007-08-15 14:28:22 +0000540
R David Murray6db23352012-09-30 20:44:43 -0400541 .. literalinclude:: ../includes/sqlite3/executemany_1.py
Georg Brandl116aa622007-08-15 14:28:22 +0000542
R David Murray6db23352012-09-30 20:44:43 -0400543 Here's a shorter example using a :term:`generator`:
Georg Brandl116aa622007-08-15 14:28:22 +0000544
R David Murray6db23352012-09-30 20:44:43 -0400545 .. literalinclude:: ../includes/sqlite3/executemany_2.py
Georg Brandl116aa622007-08-15 14:28:22 +0000546
547
R David Murray6db23352012-09-30 20:44:43 -0400548 .. method:: executescript(sql_script)
Georg Brandl116aa622007-08-15 14:28:22 +0000549
R David Murray6db23352012-09-30 20:44:43 -0400550 This is a nonstandard convenience method for executing multiple SQL statements
551 at once. It issues a ``COMMIT`` statement first, then executes the SQL script it
552 gets as a parameter.
Georg Brandl116aa622007-08-15 14:28:22 +0000553
R David Murray6db23352012-09-30 20:44:43 -0400554 *sql_script* can be an instance of :class:`str` or :class:`bytes`.
Georg Brandl116aa622007-08-15 14:28:22 +0000555
R David Murray6db23352012-09-30 20:44:43 -0400556 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000557
R David Murray6db23352012-09-30 20:44:43 -0400558 .. literalinclude:: ../includes/sqlite3/executescript.py
Georg Brandl116aa622007-08-15 14:28:22 +0000559
560
R David Murray6db23352012-09-30 20:44:43 -0400561 .. method:: fetchone()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000562
R David Murray6db23352012-09-30 20:44:43 -0400563 Fetches the next row of a query result set, returning a single sequence,
564 or :const:`None` when no more data is available.
Christian Heimesfdab48e2008-01-20 09:06:41 +0000565
566
R David Murray6db23352012-09-30 20:44:43 -0400567 .. method:: fetchmany(size=cursor.arraysize)
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000568
R David Murray6db23352012-09-30 20:44:43 -0400569 Fetches the next set of rows of a query result, returning a list. An empty
570 list is returned when no more rows are available.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000571
R David Murray6db23352012-09-30 20:44:43 -0400572 The number of rows to fetch per call is specified by the *size* parameter.
573 If it is not given, the cursor's arraysize determines the number of rows
574 to be fetched. The method should try to fetch as many rows as indicated by
575 the size parameter. If this is not possible due to the specified number of
576 rows not being available, fewer rows may be returned.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000577
R David Murray6db23352012-09-30 20:44:43 -0400578 Note there are performance considerations involved with the *size* parameter.
579 For optimal performance, it is usually best to use the arraysize attribute.
580 If the *size* parameter is used, then it is best for it to retain the same
581 value from one :meth:`fetchmany` call to the next.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000582
R David Murray6db23352012-09-30 20:44:43 -0400583 .. method:: fetchall()
Christian Heimesfdab48e2008-01-20 09:06:41 +0000584
R David Murray6db23352012-09-30 20:44:43 -0400585 Fetches all (remaining) rows of a query result, returning a list. Note that
586 the cursor's arraysize attribute can affect the performance of this operation.
587 An empty list is returned when no rows are available.
Christian Heimesfdab48e2008-01-20 09:06:41 +0000588
589
R David Murray6db23352012-09-30 20:44:43 -0400590 .. attribute:: rowcount
Georg Brandl116aa622007-08-15 14:28:22 +0000591
R David Murray6db23352012-09-30 20:44:43 -0400592 Although the :class:`Cursor` class of the :mod:`sqlite3` module implements this
593 attribute, the database engine's own support for the determination of "rows
594 affected"/"rows selected" is quirky.
Georg Brandl116aa622007-08-15 14:28:22 +0000595
R David Murray6db23352012-09-30 20:44:43 -0400596 For :meth:`executemany` statements, the number of modifications are summed up
597 into :attr:`rowcount`.
Georg Brandl116aa622007-08-15 14:28:22 +0000598
R David Murray6db23352012-09-30 20:44:43 -0400599 As required by the Python DB API Spec, the :attr:`rowcount` attribute "is -1 in
600 case no ``executeXX()`` has been performed on the cursor or the rowcount of the
601 last operation is not determinable by the interface". This includes ``SELECT``
602 statements because we cannot determine the number of rows a query produced
603 until all rows were fetched.
Georg Brandl116aa622007-08-15 14:28:22 +0000604
R David Murray6db23352012-09-30 20:44:43 -0400605 With SQLite versions before 3.6.5, :attr:`rowcount` is set to 0 if
606 you make a ``DELETE FROM table`` without any condition.
Guido van Rossum04110fb2007-08-24 16:32:05 +0000607
R David Murray6db23352012-09-30 20:44:43 -0400608 .. attribute:: lastrowid
Gerhard Häringd3372792008-03-29 19:13:55 +0000609
R David Murray6db23352012-09-30 20:44:43 -0400610 This read-only attribute provides the rowid of the last modified row. It is
611 only set if you issued a ``INSERT`` statement using the :meth:`execute`
612 method. For operations other than ``INSERT`` or when :meth:`executemany` is
613 called, :attr:`lastrowid` is set to :const:`None`.
Georg Brandl116aa622007-08-15 14:28:22 +0000614
R David Murray6db23352012-09-30 20:44:43 -0400615 .. attribute:: description
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000616
R David Murray6db23352012-09-30 20:44:43 -0400617 This read-only attribute provides the column names of the last query. To
618 remain compatible with the Python DB API, it returns a 7-tuple for each
619 column where the last six items of each tuple are :const:`None`.
Georg Brandl48310cd2009-01-03 21:18:54 +0000620
R David Murray6db23352012-09-30 20:44:43 -0400621 It is set for ``SELECT`` statements without any matching rows as well.
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000622
623.. _sqlite3-row-objects:
624
625Row Objects
626-----------
627
628.. class:: Row
629
630 A :class:`Row` instance serves as a highly optimized
Georg Brandl48310cd2009-01-03 21:18:54 +0000631 :attr:`~Connection.row_factory` for :class:`Connection` objects.
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000632 It tries to mimic a tuple in most of its features.
633
634 It supports mapping access by column name and index, iteration,
635 representation, equality testing and :func:`len`.
636
637 If two :class:`Row` objects have exactly the same columns and their
638 members are equal, they compare equal.
Georg Brandl48310cd2009-01-03 21:18:54 +0000639
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000640 .. method:: keys
641
642 This method returns a tuple of column names. Immediately after a query,
643 it is the first member of each tuple in :attr:`Cursor.description`.
644
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000645Let's assume we initialize a table as in the example given above::
646
Senthil Kumaran946eb862011-07-03 10:17:22 -0700647 conn = sqlite3.connect(":memory:")
648 c = conn.cursor()
649 c.execute('''create table stocks
650 (date text, trans text, symbol text,
651 qty real, price real)''')
652 c.execute("""insert into stocks
653 values ('2006-01-05','BUY','RHAT',100,35.14)""")
654 conn.commit()
655 c.close()
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000656
657Now we plug :class:`Row` in::
658
Senthil Kumaran946eb862011-07-03 10:17:22 -0700659 >>> conn.row_factory = sqlite3.Row
660 >>> c = conn.cursor()
661 >>> c.execute('select * from stocks')
662 <sqlite3.Cursor object at 0x7f4e7dd8fa80>
663 >>> r = c.fetchone()
664 >>> type(r)
665 <class 'sqlite3.Row'>
666 >>> tuple(r)
667 ('2006-01-05', 'BUY', 'RHAT', 100.0, 35.14)
668 >>> len(r)
669 5
670 >>> r[2]
671 'RHAT'
672 >>> r.keys()
673 ['date', 'trans', 'symbol', 'qty', 'price']
674 >>> r['qty']
675 100.0
676 >>> for member in r:
677 ... print(member)
678 ...
679 2006-01-05
680 BUY
681 RHAT
682 100.0
683 35.14
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000684
685
Georg Brandl116aa622007-08-15 14:28:22 +0000686.. _sqlite3-types:
687
688SQLite and Python types
689-----------------------
690
691
692Introduction
693^^^^^^^^^^^^
694
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000695SQLite natively supports the following types: ``NULL``, ``INTEGER``,
696``REAL``, ``TEXT``, ``BLOB``.
Georg Brandl116aa622007-08-15 14:28:22 +0000697
698The following Python types can thus be sent to SQLite without any problem:
699
Georg Brandlf6945182008-02-01 11:56:49 +0000700+-------------------------------+-------------+
701| Python type | SQLite type |
702+===============================+=============+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000703| :const:`None` | ``NULL`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000704+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000705| :class:`int` | ``INTEGER`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000706+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000707| :class:`float` | ``REAL`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000708+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000709| :class:`str` | ``TEXT`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000710+-------------------------------+-------------+
Antoine Pitrouf06917e2010-02-02 23:00:29 +0000711| :class:`bytes` | ``BLOB`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000712+-------------------------------+-------------+
Georg Brandl116aa622007-08-15 14:28:22 +0000713
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000714
Georg Brandl116aa622007-08-15 14:28:22 +0000715This is how SQLite types are converted to Python types by default:
716
717+-------------+---------------------------------------------+
718| SQLite type | Python type |
719+=============+=============================================+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000720| ``NULL`` | :const:`None` |
Georg Brandl116aa622007-08-15 14:28:22 +0000721+-------------+---------------------------------------------+
Ezio Melottib5845052009-09-13 05:49:25 +0000722| ``INTEGER`` | :class:`int` |
Georg Brandl116aa622007-08-15 14:28:22 +0000723+-------------+---------------------------------------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000724| ``REAL`` | :class:`float` |
Georg Brandl116aa622007-08-15 14:28:22 +0000725+-------------+---------------------------------------------+
Georg Brandlf6945182008-02-01 11:56:49 +0000726| ``TEXT`` | depends on text_factory, str by default |
Georg Brandl116aa622007-08-15 14:28:22 +0000727+-------------+---------------------------------------------+
Antoine Pitrouf06917e2010-02-02 23:00:29 +0000728| ``BLOB`` | :class:`bytes` |
Georg Brandl116aa622007-08-15 14:28:22 +0000729+-------------+---------------------------------------------+
730
731The type system of the :mod:`sqlite3` module is extensible in two ways: you can
732store additional Python types in a SQLite database via object adaptation, and
733you can let the :mod:`sqlite3` module convert SQLite types to different Python
734types via converters.
735
736
737Using adapters to store additional Python types in SQLite databases
738^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
739
740As described before, SQLite supports only a limited set of types natively. To
741use other Python types with SQLite, you must **adapt** them to one of the
Georg Brandl5c106642007-11-29 17:41:05 +0000742sqlite3 module's supported types for SQLite: one of NoneType, int, float,
Antoine Pitrouf06917e2010-02-02 23:00:29 +0000743str, bytes.
Georg Brandl116aa622007-08-15 14:28:22 +0000744
745The :mod:`sqlite3` module uses Python object adaptation, as described in
746:pep:`246` for this. The protocol to use is :class:`PrepareProtocol`.
747
748There are two ways to enable the :mod:`sqlite3` module to adapt a custom Python
749type to one of the supported ones.
750
751
752Letting your object adapt itself
753""""""""""""""""""""""""""""""""
754
755This is a good approach if you write the class yourself. Let's suppose you have
756a class like this::
757
Éric Araujo28053fb2010-11-22 03:09:19 +0000758 class Point:
Georg Brandl116aa622007-08-15 14:28:22 +0000759 def __init__(self, x, y):
760 self.x, self.y = x, y
761
762Now you want to store the point in a single SQLite column. First you'll have to
763choose one of the supported types first to be used for representing the point.
764Let's just use str and separate the coordinates using a semicolon. Then you need
765to give your class a method ``__conform__(self, protocol)`` which must return
766the converted value. The parameter *protocol* will be :class:`PrepareProtocol`.
767
768.. literalinclude:: ../includes/sqlite3/adapter_point_1.py
769
770
771Registering an adapter callable
772"""""""""""""""""""""""""""""""
773
774The other possibility is to create a function that converts the type to the
775string representation and register the function with :meth:`register_adapter`.
776
Georg Brandl116aa622007-08-15 14:28:22 +0000777.. literalinclude:: ../includes/sqlite3/adapter_point_2.py
778
779The :mod:`sqlite3` module has two default adapters for Python's built-in
780:class:`datetime.date` and :class:`datetime.datetime` types. Now let's suppose
781we want to store :class:`datetime.datetime` objects not in ISO representation,
782but as a Unix timestamp.
783
784.. literalinclude:: ../includes/sqlite3/adapter_datetime.py
785
786
787Converting SQLite values to custom Python types
788^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
789
790Writing an adapter lets you send custom Python types to SQLite. But to make it
791really useful we need to make the Python to SQLite to Python roundtrip work.
792
793Enter converters.
794
795Let's go back to the :class:`Point` class. We stored the x and y coordinates
796separated via semicolons as strings in SQLite.
797
798First, we'll define a converter function that accepts the string as a parameter
799and constructs a :class:`Point` object from it.
800
801.. note::
802
803 Converter functions **always** get called with a string, no matter under which
804 data type you sent the value to SQLite.
805
Georg Brandl116aa622007-08-15 14:28:22 +0000806::
807
808 def convert_point(s):
Petri Lehtinen1ca93952012-02-15 22:17:21 +0200809 x, y = map(float, s.split(b";"))
Georg Brandl116aa622007-08-15 14:28:22 +0000810 return Point(x, y)
811
812Now you need to make the :mod:`sqlite3` module know that what you select from
813the database is actually a point. There are two ways of doing this:
814
815* Implicitly via the declared type
816
817* Explicitly via the column name
818
819Both ways are described in section :ref:`sqlite3-module-contents`, in the entries
820for the constants :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`.
821
822The following example illustrates both approaches.
823
824.. literalinclude:: ../includes/sqlite3/converter_point.py
825
826
827Default adapters and converters
828^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
829
830There are default adapters for the date and datetime types in the datetime
831module. They will be sent as ISO dates/ISO timestamps to SQLite.
832
833The default converters are registered under the name "date" for
834:class:`datetime.date` and under the name "timestamp" for
835:class:`datetime.datetime`.
836
837This way, you can use date/timestamps from Python without any additional
838fiddling in most cases. The format of the adapters is also compatible with the
839experimental SQLite date/time functions.
840
841The following example demonstrates this.
842
843.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py
844
Petri Lehtinen5f794092013-02-26 21:32:02 +0200845If a timestamp stored in SQLite has a fractional part longer than 6
846numbers, its value will be truncated to microsecond precision by the
847timestamp converter.
848
Georg Brandl116aa622007-08-15 14:28:22 +0000849
850.. _sqlite3-controlling-transactions:
851
852Controlling Transactions
853------------------------
854
855By default, the :mod:`sqlite3` module opens transactions implicitly before a
Georg Brandl48310cd2009-01-03 21:18:54 +0000856Data Modification Language (DML) statement (i.e.
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000857``INSERT``/``UPDATE``/``DELETE``/``REPLACE``), and commits transactions
858implicitly before a non-DML, non-query statement (i. e.
859anything other than ``SELECT`` or the aforementioned).
Georg Brandl116aa622007-08-15 14:28:22 +0000860
861So if you are within a transaction and issue a command like ``CREATE TABLE
862...``, ``VACUUM``, ``PRAGMA``, the :mod:`sqlite3` module will commit implicitly
863before executing that command. There are two reasons for doing that. The first
864is that some of these commands don't work within transactions. The other reason
Georg Brandl8a1e4c42009-05-25 21:13:36 +0000865is that sqlite3 needs to keep track of the transaction state (if a transaction
R. David Murrayd35251d2010-06-01 01:32:12 +0000866is active or not). The current transaction state is exposed through the
867:attr:`Connection.in_transaction` attribute of the connection object.
Georg Brandl116aa622007-08-15 14:28:22 +0000868
Georg Brandl8a1e4c42009-05-25 21:13:36 +0000869You can control which kind of ``BEGIN`` statements sqlite3 implicitly executes
Georg Brandl116aa622007-08-15 14:28:22 +0000870(or none at all) via the *isolation_level* parameter to the :func:`connect`
871call, or via the :attr:`isolation_level` property of connections.
872
873If you want **autocommit mode**, then set :attr:`isolation_level` to None.
874
875Otherwise leave it at its default, which will result in a plain "BEGIN"
Georg Brandla971c652008-11-07 09:39:56 +0000876statement, or set it to one of SQLite's supported isolation levels: "DEFERRED",
877"IMMEDIATE" or "EXCLUSIVE".
Georg Brandl116aa622007-08-15 14:28:22 +0000878
Georg Brandl116aa622007-08-15 14:28:22 +0000879
880
Georg Brandl8a1e4c42009-05-25 21:13:36 +0000881Using :mod:`sqlite3` efficiently
882--------------------------------
Georg Brandl116aa622007-08-15 14:28:22 +0000883
884
885Using shortcut methods
886^^^^^^^^^^^^^^^^^^^^^^
887
888Using the nonstandard :meth:`execute`, :meth:`executemany` and
889:meth:`executescript` methods of the :class:`Connection` object, your code can
890be written more concisely because you don't have to create the (often
891superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
892objects are created implicitly and these shortcut methods return the cursor
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000893objects. This way, you can execute a ``SELECT`` statement and iterate over it
Georg Brandl116aa622007-08-15 14:28:22 +0000894directly using only a single call on the :class:`Connection` object.
895
896.. literalinclude:: ../includes/sqlite3/shortcut_methods.py
897
898
899Accessing columns by name instead of by index
900^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
901
Georg Brandl22b34312009-07-26 14:54:51 +0000902One useful feature of the :mod:`sqlite3` module is the built-in
Georg Brandl116aa622007-08-15 14:28:22 +0000903:class:`sqlite3.Row` class designed to be used as a row factory.
904
905Rows wrapped with this class can be accessed both by index (like tuples) and
906case-insensitively by name:
907
908.. literalinclude:: ../includes/sqlite3/rowclass.py
909
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000910
911Using the connection as a context manager
912^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
913
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000914Connection objects can be used as context managers
915that automatically commit or rollback transactions. In the event of an
916exception, the transaction is rolled back; otherwise, the transaction is
917committed:
918
919.. literalinclude:: ../includes/sqlite3/ctx_manager.py
Gerhard Häringc34d76c2010-08-06 06:12:05 +0000920
921
922Common issues
923-------------
924
925Multithreading
926^^^^^^^^^^^^^^
927
928Older SQLite versions had issues with sharing connections between threads.
929That's why the Python module disallows sharing connections and cursors between
930threads. If you still try to do so, you will get an exception at runtime.
931
932The only exception is calling the :meth:`~Connection.interrupt` method, which
933only makes sense to call from a different thread.
934
Gerhard Häringe0941c52010-10-03 21:47:06 +0000935.. rubric:: Footnotes
936
937.. [#f1] The sqlite3 module is not built with loadable extension support by
Senthil Kumaran946eb862011-07-03 10:17:22 -0700938 default, because some platforms (notably Mac OS X) have SQLite
939 libraries which are compiled without this feature. To get loadable
940 extension support, you must pass --enable-loadable-sqlite-extensions to
941 configure.