blob: 16d2c2e85f42b52a780eafef99e25b43ad209c98 [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.
Terry Jan Reedyfa089b92016-06-11 15:02:54 -04006
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +02007.. sectionauthor:: Gerhard Häring <gh@ghaering.de>
Georg Brandl116aa622007-08-15 14:28:22 +00008
Terry Jan Reedyfa089b92016-06-11 15:02:54 -04009**Source code:** :source:`Lib/sqlite3/`
10
11--------------
Georg Brandl116aa622007-08-15 14:28:22 +000012
Georg Brandl116aa622007-08-15 14:28:22 +000013SQLite is a C library that provides a lightweight disk-based database that
14doesn't require a separate server process and allows accessing the database
15using a nonstandard variant of the SQL query language. Some applications can use
16SQLite for internal data storage. It's also possible to prototype an
17application using SQLite and then port the code to a larger database such as
18PostgreSQL or Oracle.
19
Zachary Ware9d085622014-04-01 12:21:56 -050020The sqlite3 module was written by Gerhard Häring. It provides a SQL interface
Erlend Egeberg Aasland207c3212020-09-07 23:26:54 +020021compliant with the DB-API 2.0 specification described by :pep:`249`, and
Erlend Egeberg Aaslandcf0b2392021-01-06 01:02:43 +010022requires SQLite 3.7.15 or newer.
Georg Brandl116aa622007-08-15 14:28:22 +000023
24To use the module, you must first create a :class:`Connection` object that
25represents the database. Here the data will be stored in the
Petri Lehtinen9f74c6c2013-02-23 19:26:56 +010026:file:`example.db` file::
Georg Brandl116aa622007-08-15 14:28:22 +000027
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +020028 import sqlite3
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +010029 con = sqlite3.connect('example.db')
Georg Brandl116aa622007-08-15 14:28:22 +000030
31You can also supply the special name ``:memory:`` to create a database in RAM.
32
33Once you have a :class:`Connection`, you can create a :class:`Cursor` object
Benjamin Petersonf10a79a2008-10-11 00:49:57 +000034and call its :meth:`~Cursor.execute` method to perform SQL commands::
Georg Brandl116aa622007-08-15 14:28:22 +000035
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +010036 cur = con.cursor()
Georg Brandl116aa622007-08-15 14:28:22 +000037
38 # Create table
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +010039 cur.execute('''CREATE TABLE stocks
40 (date text, trans text, symbol text, qty real, price real)''')
Georg Brandl116aa622007-08-15 14:28:22 +000041
42 # Insert a row of data
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +010043 cur.execute("INSERT INTO stocks VALUES ('2006-01-05','BUY','RHAT',100,35.14)")
Georg Brandl116aa622007-08-15 14:28:22 +000044
45 # Save (commit) the changes
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +010046 con.commit()
Georg Brandl116aa622007-08-15 14:28:22 +000047
Zachary Ware9d085622014-04-01 12:21:56 -050048 # We can also close the connection if we are done with it.
49 # Just be sure any changes have been committed or they will be lost.
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +010050 con.close()
Zachary Ware9d085622014-04-01 12:21:56 -050051
52The data you've saved is persistent and is available in subsequent sessions::
53
54 import sqlite3
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +010055 con = sqlite3.connect('example.db')
56 cur = con.cursor()
Georg Brandl116aa622007-08-15 14:28:22 +000057
Georg Brandl9afde1c2007-11-01 20:32:30 +000058To retrieve data after executing a SELECT statement, you can either treat the
Benjamin Petersonf10a79a2008-10-11 00:49:57 +000059cursor as an :term:`iterator`, call the cursor's :meth:`~Cursor.fetchone` method to
60retrieve a single matching row, or call :meth:`~Cursor.fetchall` to get a list of the
Georg Brandl9afde1c2007-11-01 20:32:30 +000061matching rows.
Georg Brandl116aa622007-08-15 14:28:22 +000062
63This example uses the iterator form::
64
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +010065 >>> for row in cur.execute('SELECT * FROM stocks ORDER BY price'):
Zachary Ware9d085622014-04-01 12:21:56 -050066 print(row)
67
Ezio Melottib5845052009-09-13 05:49:25 +000068 ('2006-01-05', 'BUY', 'RHAT', 100, 35.14)
69 ('2006-03-28', 'BUY', 'IBM', 1000, 45.0)
70 ('2006-04-06', 'SELL', 'IBM', 500, 53.0)
Zachary Ware9d085622014-04-01 12:21:56 -050071 ('2006-04-05', 'BUY', 'MSFT', 1000, 72.0)
Georg Brandl116aa622007-08-15 14:28:22 +000072
73
Erlend Egeberg Aasland3386ca02021-04-14 14:28:55 +020074.. _sqlite3-placeholders:
75
76Usually your SQL operations will need to use values from Python variables. You
77shouldn't assemble your query using Python's string operations because doing so
78is insecure; it makes your program vulnerable to an SQL injection attack
79(see the `xkcd webcomic <https://xkcd.com/327/>`_ for a humorous example of
80what can go wrong)::
81
82 # Never do this -- insecure!
83 symbol = 'RHAT'
84 cur.execute("SELECT * FROM stocks WHERE symbol = '%s'" % symbol)
85
86Instead, use the DB-API's parameter substitution. Put a placeholder wherever
87you want to use a value, and then provide a tuple of values as the second
88argument to the cursor's :meth:`~Cursor.execute` method. An SQL statement may
89use one of two kinds of placeholders: question marks (qmark style) or named
90placeholders (named style). For the qmark style, ``parameters`` must be a
91:term:`sequence <sequence>`. For the named style, it can be either a
92:term:`sequence <sequence>` or :class:`dict` instance. The length of the
93:term:`sequence <sequence>` must match the number of placeholders, or a
94:exc:`ProgrammingError` is raised. If a :class:`dict` is given, it must contain
95keys for all named parameters. Any extra items are ignored. Here's an example
96of both styles:
97
98.. literalinclude:: ../includes/sqlite3/execute_1.py
99
100
Georg Brandl116aa622007-08-15 14:28:22 +0000101.. seealso::
102
Serhiy Storchaka6dff0202016-05-07 10:49:07 +0300103 https://www.sqlite.org
Georg Brandl8a1e4c42009-05-25 21:13:36 +0000104 The SQLite web page; the documentation describes the syntax and the
105 available data types for the supported SQL dialect.
Georg Brandl116aa622007-08-15 14:28:22 +0000106
Sanyam Khurana1b4587a2017-12-06 22:09:33 +0530107 https://www.w3schools.com/sql/
Zachary Ware9d085622014-04-01 12:21:56 -0500108 Tutorial, reference and examples for learning SQL syntax.
109
Georg Brandl116aa622007-08-15 14:28:22 +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
Miss Islington (bot)1d88b2b2021-10-28 12:57:14 -0700120.. data:: apilevel
121
122 String constant stating the supported DB-API level. Required by the DB-API.
123 Hard-coded to ``"2.0"``.
124
125.. data:: paramstyle
126
127 String constant stating the type of parameter marker formatting expected by
128 the :mod:`sqlite3` module. Required by the DB-API. Hard-coded to
129 ``"qmark"``.
130
131 .. note::
132
133 The :mod:`sqlite3` module supports both ``qmark`` and ``numeric`` DB-API
134 parameter styles, because that is what the underlying SQLite library
135 supports. However, the DB-API does not allow multiple values for
136 the ``paramstyle`` attribute.
137
R David Murray3f7beb92013-01-10 20:18:21 -0500138.. data:: version
139
140 The version number of this module, as a string. This is not the version of
141 the SQLite library.
142
143
144.. data:: version_info
145
146 The version number of this module, as a tuple of integers. This is not the
147 version of the SQLite library.
148
149
150.. data:: sqlite_version
151
152 The version number of the run-time SQLite library, as a string.
153
154
155.. data:: sqlite_version_info
156
157 The version number of the run-time SQLite library, as a tuple of integers.
158
159
Miss Islington (bot)1d88b2b2021-10-28 12:57:14 -0700160.. data:: threadsafety
161
162 Integer constant required by the DB-API, stating the level of thread safety
163 the :mod:`sqlite3` module supports. Currently hard-coded to ``1``, meaning
164 *"Threads may share the module, but not connections."* However, this may not
165 always be true. You can check the underlying SQLite library's compile-time
166 threaded mode using the following query::
167
168 import sqlite3
169 con = sqlite3.connect(":memory:")
170 con.execute("""
171 select * from pragma_compile_options
172 where compile_options like 'THREADSAFE=%'
173 """).fetchall()
174
175 Note that the `SQLITE_THREADSAFE levels
176 <https://sqlite.org/compile.html#threadsafe>`_ do not match the DB-API 2.0
177 ``threadsafety`` levels.
178
179
Georg Brandl116aa622007-08-15 14:28:22 +0000180.. data:: PARSE_DECLTYPES
181
182 This constant is meant to be used with the *detect_types* parameter of the
183 :func:`connect` function.
184
185 Setting it makes the :mod:`sqlite3` module parse the declared type for each
Christian Heimes81ee3ef2008-05-04 22:42:01 +0000186 column it returns. It will parse out the first word of the declared type,
187 i. e. for "integer primary key", it will parse out "integer", or for
188 "number(10)" it will parse out "number". Then for that column, it will look
189 into the converters dictionary and use the converter function registered for
190 that type there.
Georg Brandl116aa622007-08-15 14:28:22 +0000191
192
193.. data:: PARSE_COLNAMES
194
195 This constant is meant to be used with the *detect_types* parameter of the
196 :func:`connect` function.
197
198 Setting this makes the SQLite interface parse the column name for each column it
199 returns. It will look for a string formed [mytype] in there, and then decide
200 that 'mytype' is the type of the column. It will try to find an entry of
201 'mytype' in the converters dictionary and then use the converter function found
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000202 there to return the value. The column name found in :attr:`Cursor.description`
Serhiy Storchakab1465682020-03-21 15:53:28 +0200203 does not include the type, i. e. if you use something like
204 ``'as "Expiration date [datetime]"'`` in your SQL, then we will parse out
205 everything until the first ``'['`` for the column name and strip
Miss Islington (bot)a90a57e2021-07-28 07:33:26 -0700206 the preceding space: the column name would simply be "Expiration date".
Georg Brandl116aa622007-08-15 14:28:22 +0000207
208
Antoine Pitrou902fc8b2013-02-10 00:02:44 +0100209.. function:: connect(database[, timeout, detect_types, isolation_level, check_same_thread, factory, cached_statements, uri])
Georg Brandl116aa622007-08-15 14:28:22 +0000210
Anders Lorentsena22a1272017-11-07 01:47:43 +0100211 Opens a connection to the SQLite database file *database*. By default returns a
212 :class:`Connection` object, unless a custom *factory* is given.
213
214 *database* is a :term:`path-like object` giving the pathname (absolute or
215 relative to the current working directory) of the database file to be opened.
216 You can use ``":memory:"`` to open a database connection to a database that
217 resides in RAM instead of on disk.
Georg Brandl116aa622007-08-15 14:28:22 +0000218
219 When a database is accessed by multiple connections, and one of the processes
220 modifies the database, the SQLite database is locked until that transaction is
221 committed. The *timeout* parameter specifies how long the connection should wait
222 for the lock to go away until raising an exception. The default for the timeout
223 parameter is 5.0 (five seconds).
224
225 For the *isolation_level* parameter, please see the
Berker Peksaga1bc2462016-09-07 04:02:41 +0300226 :attr:`~Connection.isolation_level` property of :class:`Connection` objects.
Georg Brandl116aa622007-08-15 14:28:22 +0000227
Georg Brandl3c127112013-10-06 12:38:44 +0200228 SQLite natively supports only the types TEXT, INTEGER, REAL, BLOB and NULL. If
Georg Brandl116aa622007-08-15 14:28:22 +0000229 you want to use other types you must add support for them yourself. The
230 *detect_types* parameter and the using custom **converters** registered with the
231 module-level :func:`register_converter` function allow you to easily do that.
232
233 *detect_types* defaults to 0 (i. e. off, no type detection), you can set it to
234 any combination of :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES` to turn
sblondon09a36cd2020-12-19 23:52:39 +0100235 type detection on. Due to SQLite behaviour, types can't be detected for generated
236 fields (for example ``max(data)``), even when *detect_types* parameter is set. In
237 such case, the returned type is :class:`str`.
Georg Brandl116aa622007-08-15 14:28:22 +0000238
Senthil Kumaran7ee91942016-06-03 00:03:48 -0700239 By default, *check_same_thread* is :const:`True` and only the creating thread may
240 use the connection. If set :const:`False`, the returned connection may be shared
241 across multiple threads. When using multiple threads with the same connection
242 writing operations should be serialized by the user to avoid data corruption.
243
Georg Brandl116aa622007-08-15 14:28:22 +0000244 By default, the :mod:`sqlite3` module uses its :class:`Connection` class for the
245 connect call. You can, however, subclass the :class:`Connection` class and make
246 :func:`connect` use your class instead by providing your class for the *factory*
247 parameter.
248
249 Consult the section :ref:`sqlite3-types` of this manual for details.
250
251 The :mod:`sqlite3` module internally uses a statement cache to avoid SQL parsing
252 overhead. If you want to explicitly set the number of statements that are cached
253 for the connection, you can set the *cached_statements* parameter. The currently
254 implemented default is to cache 100 statements.
255
Antoine Pitrou902fc8b2013-02-10 00:02:44 +0100256 If *uri* is true, *database* is interpreted as a URI. This allows you
257 to specify options. For example, to open a database in read-only mode
258 you can use::
259
260 db = sqlite3.connect('file:path/to/database?mode=ro', uri=True)
261
262 More information about this feature, including a list of recognized options, can
Serhiy Storchaka6dff0202016-05-07 10:49:07 +0300263 be found in the `SQLite URI documentation <https://www.sqlite.org/uri.html>`_.
Antoine Pitrou902fc8b2013-02-10 00:02:44 +0100264
Steve Dower44f91c32019-06-27 10:47:59 -0700265 .. audit-event:: sqlite3.connect database sqlite3.connect
Erlend Egeberg Aasland7244c002021-04-27 01:16:46 +0200266 .. audit-event:: sqlite3.connect/handle connection_handle sqlite3.connect
Steve Dower60419a72019-06-24 08:42:54 -0700267
Antoine Pitrou902fc8b2013-02-10 00:02:44 +0100268 .. versionchanged:: 3.4
269 Added the *uri* parameter.
270
Anders Lorentsena22a1272017-11-07 01:47:43 +0100271 .. versionchanged:: 3.7
272 *database* can now also be a :term:`path-like object`, not only a string.
273
Erlend Egeberg Aasland7244c002021-04-27 01:16:46 +0200274 .. versionchanged:: 3.10
275 Added the ``sqlite3.connect/handle`` auditing event.
276
Georg Brandl116aa622007-08-15 14:28:22 +0000277
278.. function:: register_converter(typename, callable)
279
280 Registers a callable to convert a bytestring from the database into a custom
281 Python type. The callable will be invoked for all database values that are of
282 the type *typename*. Confer the parameter *detect_types* of the :func:`connect`
Sergey Fedoseev831c2972018-07-03 16:59:32 +0500283 function for how the type detection works. Note that *typename* and the name of
284 the type in your query are matched in case-insensitive manner.
Georg Brandl116aa622007-08-15 14:28:22 +0000285
286
287.. function:: register_adapter(type, callable)
288
289 Registers a callable to convert the custom Python type *type* into one of
290 SQLite's supported types. The callable *callable* accepts as single parameter
Georg Brandl5c106642007-11-29 17:41:05 +0000291 the Python value, and must return a value of the following types: int,
Antoine Pitrouf06917e2010-02-02 23:00:29 +0000292 float, str or bytes.
Georg Brandl116aa622007-08-15 14:28:22 +0000293
294
295.. function:: complete_statement(sql)
296
297 Returns :const:`True` if the string *sql* contains one or more complete SQL
298 statements terminated by semicolons. It does not verify that the SQL is
299 syntactically correct, only that there are no unclosed string literals and the
300 statement is terminated by a semicolon.
301
302 This can be used to build a shell for SQLite, as in the following example:
303
304
305 .. literalinclude:: ../includes/sqlite3/complete_statement.py
306
307
308.. function:: enable_callback_tracebacks(flag)
309
310 By default you will not get any tracebacks in user-defined functions,
Serhiy Storchakafbc1c262013-11-29 12:17:13 +0200311 aggregates, converters, authorizer callbacks etc. If you want to debug them,
312 you can call this function with *flag* set to ``True``. Afterwards, you will
313 get tracebacks from callbacks on ``sys.stderr``. Use :const:`False` to
314 disable the feature again.
Georg Brandl116aa622007-08-15 14:28:22 +0000315
316
317.. _sqlite3-connection-objects:
318
319Connection Objects
320------------------
321
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000322.. class:: Connection
323
324 A SQLite database connection has the following attributes and methods:
Georg Brandl116aa622007-08-15 14:28:22 +0000325
R David Murray6db23352012-09-30 20:44:43 -0400326 .. attribute:: isolation_level
Georg Brandl116aa622007-08-15 14:28:22 +0000327
Berker Peksaga71fed02018-07-29 12:01:38 +0300328 Get or set the current default isolation level. :const:`None` for autocommit mode or
R David Murray6db23352012-09-30 20:44:43 -0400329 one of "DEFERRED", "IMMEDIATE" or "EXCLUSIVE". See section
330 :ref:`sqlite3-controlling-transactions` for a more detailed explanation.
Georg Brandl116aa622007-08-15 14:28:22 +0000331
R David Murray6db23352012-09-30 20:44:43 -0400332 .. attribute:: in_transaction
R. David Murrayd35251d2010-06-01 01:32:12 +0000333
R David Murray6db23352012-09-30 20:44:43 -0400334 :const:`True` if a transaction is active (there are uncommitted changes),
335 :const:`False` otherwise. Read-only attribute.
R. David Murrayd35251d2010-06-01 01:32:12 +0000336
R David Murray6db23352012-09-30 20:44:43 -0400337 .. versionadded:: 3.2
Georg Brandl116aa622007-08-15 14:28:22 +0000338
Serhiy Storchakaef113cd2016-08-29 14:29:55 +0300339 .. method:: cursor(factory=Cursor)
Georg Brandl116aa622007-08-15 14:28:22 +0000340
Serhiy Storchakaef113cd2016-08-29 14:29:55 +0300341 The cursor method accepts a single optional parameter *factory*. If
342 supplied, this must be a callable returning an instance of :class:`Cursor`
343 or its subclasses.
Georg Brandl116aa622007-08-15 14:28:22 +0000344
R David Murray6db23352012-09-30 20:44:43 -0400345 .. method:: commit()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000346
R David Murray6db23352012-09-30 20:44:43 -0400347 This method commits the current transaction. If you don't call this method,
348 anything you did since the last call to ``commit()`` is not visible from
349 other database connections. If you wonder why you don't see the data you've
350 written to the database, please check you didn't forget to call this method.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000351
R David Murray6db23352012-09-30 20:44:43 -0400352 .. method:: rollback()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000353
R David Murray6db23352012-09-30 20:44:43 -0400354 This method rolls back any changes to the database since the last call to
355 :meth:`commit`.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000356
R David Murray6db23352012-09-30 20:44:43 -0400357 .. method:: close()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000358
R David Murray6db23352012-09-30 20:44:43 -0400359 This closes the database connection. Note that this does not automatically
360 call :meth:`commit`. If you just close your database connection without
361 calling :meth:`commit` first, your changes will be lost!
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000362
Berker Peksagc4154402016-06-12 13:41:47 +0300363 .. method:: execute(sql[, parameters])
Georg Brandl116aa622007-08-15 14:28:22 +0000364
Berker Peksagc4154402016-06-12 13:41:47 +0300365 This is a nonstandard shortcut that creates a cursor object by calling
366 the :meth:`~Connection.cursor` method, calls the cursor's
367 :meth:`~Cursor.execute` method with the *parameters* given, and returns
368 the cursor.
Georg Brandl116aa622007-08-15 14:28:22 +0000369
Berker Peksagc4154402016-06-12 13:41:47 +0300370 .. method:: executemany(sql[, parameters])
Georg Brandl116aa622007-08-15 14:28:22 +0000371
Berker Peksagc4154402016-06-12 13:41:47 +0300372 This is a nonstandard shortcut that creates a cursor object by
373 calling the :meth:`~Connection.cursor` method, calls the cursor's
374 :meth:`~Cursor.executemany` method with the *parameters* given, and
375 returns the cursor.
Georg Brandl116aa622007-08-15 14:28:22 +0000376
R David Murray6db23352012-09-30 20:44:43 -0400377 .. method:: executescript(sql_script)
Georg Brandl116aa622007-08-15 14:28:22 +0000378
Berker Peksagc4154402016-06-12 13:41:47 +0300379 This is a nonstandard shortcut that creates a cursor object by
380 calling the :meth:`~Connection.cursor` method, calls the cursor's
381 :meth:`~Cursor.executescript` method with the given *sql_script*, and
382 returns the cursor.
Georg Brandl116aa622007-08-15 14:28:22 +0000383
Sergey Fedoseev08308582018-07-08 12:09:20 +0500384 .. method:: create_function(name, num_params, func, *, deterministic=False)
Georg Brandl116aa622007-08-15 14:28:22 +0000385
R David Murray6db23352012-09-30 20:44:43 -0400386 Creates a user-defined function that you can later use from within SQL
387 statements under the function name *name*. *num_params* is the number of
Berker Peksagfa0f62d2016-03-27 22:39:14 +0300388 parameters the function accepts (if *num_params* is -1, the function may
389 take any number of arguments), and *func* is a Python callable that is
Sergey Fedoseev08308582018-07-08 12:09:20 +0500390 called as the SQL function. If *deterministic* is true, the created function
391 is marked as `deterministic <https://sqlite.org/deterministic.html>`_, which
392 allows SQLite to perform additional optimizations. This flag is supported by
Marcin Niemirabc9aa812018-07-08 14:02:58 +0200393 SQLite 3.8.3 or higher, :exc:`NotSupportedError` will be raised if used
Sergey Fedoseev08308582018-07-08 12:09:20 +0500394 with older versions.
Georg Brandl116aa622007-08-15 14:28:22 +0000395
R David Murray6db23352012-09-30 20:44:43 -0400396 The function can return any of the types supported by SQLite: bytes, str, int,
Serhiy Storchakaecf41da2016-10-19 16:29:26 +0300397 float and ``None``.
Georg Brandl116aa622007-08-15 14:28:22 +0000398
Sergey Fedoseev08308582018-07-08 12:09:20 +0500399 .. versionchanged:: 3.8
400 The *deterministic* parameter was added.
401
R David Murray6db23352012-09-30 20:44:43 -0400402 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000403
R David Murray6db23352012-09-30 20:44:43 -0400404 .. literalinclude:: ../includes/sqlite3/md5func.py
Georg Brandl116aa622007-08-15 14:28:22 +0000405
406
R David Murray6db23352012-09-30 20:44:43 -0400407 .. method:: create_aggregate(name, num_params, aggregate_class)
Georg Brandl116aa622007-08-15 14:28:22 +0000408
R David Murray6db23352012-09-30 20:44:43 -0400409 Creates a user-defined aggregate function.
Georg Brandl116aa622007-08-15 14:28:22 +0000410
R David Murray6db23352012-09-30 20:44:43 -0400411 The aggregate class must implement a ``step`` method, which accepts the number
Berker Peksagfa0f62d2016-03-27 22:39:14 +0300412 of parameters *num_params* (if *num_params* is -1, the function may take
413 any number of arguments), and a ``finalize`` method which will return the
R David Murray6db23352012-09-30 20:44:43 -0400414 final result of the aggregate.
Georg Brandl116aa622007-08-15 14:28:22 +0000415
R David Murray6db23352012-09-30 20:44:43 -0400416 The ``finalize`` method can return any of the types supported by SQLite:
Serhiy Storchakaecf41da2016-10-19 16:29:26 +0300417 bytes, str, int, float and ``None``.
Georg Brandl116aa622007-08-15 14:28:22 +0000418
R David Murray6db23352012-09-30 20:44:43 -0400419 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000420
R David Murray6db23352012-09-30 20:44:43 -0400421 .. literalinclude:: ../includes/sqlite3/mysumaggr.py
Georg Brandl116aa622007-08-15 14:28:22 +0000422
423
R David Murray6db23352012-09-30 20:44:43 -0400424 .. method:: create_collation(name, callable)
Georg Brandl116aa622007-08-15 14:28:22 +0000425
R David Murray6db23352012-09-30 20:44:43 -0400426 Creates a collation with the specified *name* and *callable*. The callable will
427 be passed two string arguments. It should return -1 if the first is ordered
428 lower than the second, 0 if they are ordered equal and 1 if the first is ordered
429 higher than the second. Note that this controls sorting (ORDER BY in SQL) so
430 your comparisons don't affect other SQL operations.
Georg Brandl116aa622007-08-15 14:28:22 +0000431
R David Murray6db23352012-09-30 20:44:43 -0400432 Note that the callable will get its parameters as Python bytestrings, which will
433 normally be encoded in UTF-8.
Georg Brandl116aa622007-08-15 14:28:22 +0000434
R David Murray6db23352012-09-30 20:44:43 -0400435 The following example shows a custom collation that sorts "the wrong way":
Georg Brandl116aa622007-08-15 14:28:22 +0000436
R David Murray6db23352012-09-30 20:44:43 -0400437 .. literalinclude:: ../includes/sqlite3/collation_reverse.py
Georg Brandl116aa622007-08-15 14:28:22 +0000438
Serhiy Storchakaecf41da2016-10-19 16:29:26 +0300439 To remove a collation, call ``create_collation`` with ``None`` as callable::
Georg Brandl116aa622007-08-15 14:28:22 +0000440
R David Murray6db23352012-09-30 20:44:43 -0400441 con.create_collation("reverse", None)
Georg Brandl116aa622007-08-15 14:28:22 +0000442
443
R David Murray6db23352012-09-30 20:44:43 -0400444 .. method:: interrupt()
Georg Brandl116aa622007-08-15 14:28:22 +0000445
R David Murray6db23352012-09-30 20:44:43 -0400446 You can call this method from a different thread to abort any queries that might
447 be executing on the connection. The query will then abort and the caller will
448 get an exception.
Georg Brandl116aa622007-08-15 14:28:22 +0000449
450
R David Murray6db23352012-09-30 20:44:43 -0400451 .. method:: set_authorizer(authorizer_callback)
Georg Brandl116aa622007-08-15 14:28:22 +0000452
R David Murray6db23352012-09-30 20:44:43 -0400453 This routine registers a callback. The callback is invoked for each attempt to
454 access a column of a table in the database. The callback should return
455 :const:`SQLITE_OK` if access is allowed, :const:`SQLITE_DENY` if the entire SQL
456 statement should be aborted with an error and :const:`SQLITE_IGNORE` if the
457 column should be treated as a NULL value. These constants are available in the
458 :mod:`sqlite3` module.
Georg Brandl116aa622007-08-15 14:28:22 +0000459
R David Murray6db23352012-09-30 20:44:43 -0400460 The first argument to the callback signifies what kind of operation is to be
461 authorized. The second and third argument will be arguments or :const:`None`
462 depending on the first argument. The 4th argument is the name of the database
463 ("main", "temp", etc.) if applicable. The 5th argument is the name of the
464 inner-most trigger or view that is responsible for the access attempt or
465 :const:`None` if this access attempt is directly from input SQL code.
Georg Brandl116aa622007-08-15 14:28:22 +0000466
R David Murray6db23352012-09-30 20:44:43 -0400467 Please consult the SQLite documentation about the possible values for the first
468 argument and the meaning of the second and third argument depending on the first
469 one. All necessary constants are available in the :mod:`sqlite3` module.
Georg Brandl116aa622007-08-15 14:28:22 +0000470
Georg Brandl116aa622007-08-15 14:28:22 +0000471
R David Murray6db23352012-09-30 20:44:43 -0400472 .. method:: set_progress_handler(handler, n)
Georg Brandl116aa622007-08-15 14:28:22 +0000473
R David Murray6db23352012-09-30 20:44:43 -0400474 This routine registers a callback. The callback is invoked for every *n*
475 instructions of the SQLite virtual machine. This is useful if you want to
476 get called from SQLite during long-running operations, for example to update
477 a GUI.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000478
R David Murray6db23352012-09-30 20:44:43 -0400479 If you want to clear any previously installed progress handler, call the
480 method with :const:`None` for *handler*.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000481
Simon Willisonac03c032017-11-02 07:34:12 -0700482 Returning a non-zero value from the handler function will terminate the
483 currently executing query and cause it to raise an :exc:`OperationalError`
484 exception.
485
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000486
R David Murray842ca5f2012-09-30 20:49:19 -0400487 .. method:: set_trace_callback(trace_callback)
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000488
R David Murray842ca5f2012-09-30 20:49:19 -0400489 Registers *trace_callback* to be called for each SQL statement that is
490 actually executed by the SQLite backend.
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200491
Miss Islington (bot)87f0ac82021-09-15 12:00:02 -0700492 The only argument passed to the callback is the statement (as
493 :class:`str`) that is being executed. The return value of the callback is
494 ignored. Note that the backend does not only run statements passed to the
495 :meth:`Cursor.execute` methods. Other sources include the
496 :ref:`transaction management <sqlite3-controlling-transactions>` of the
497 sqlite3 module and the execution of triggers defined in the current
498 database.
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200499
R David Murray842ca5f2012-09-30 20:49:19 -0400500 Passing :const:`None` as *trace_callback* will disable the trace callback.
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200501
Miss Islington (bot)87f0ac82021-09-15 12:00:02 -0700502 .. note::
503 Exceptions raised in the trace callback are not propagated. As a
504 development and debugging aid, use
505 :meth:`~sqlite3.enable_callback_tracebacks` to enable printing
506 tracebacks from exceptions raised in the trace callback.
507
R David Murray842ca5f2012-09-30 20:49:19 -0400508 .. versionadded:: 3.3
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200509
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200510
R David Murray6db23352012-09-30 20:44:43 -0400511 .. method:: enable_load_extension(enabled)
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200512
R David Murray6db23352012-09-30 20:44:43 -0400513 This routine allows/disallows the SQLite engine to load SQLite extensions
514 from shared libraries. SQLite extensions can define new functions,
515 aggregates or whole new virtual table implementations. One well-known
516 extension is the fulltext-search extension distributed with SQLite.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000517
R David Murray6db23352012-09-30 20:44:43 -0400518 Loadable extensions are disabled by default. See [#f1]_.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000519
Erlend Egeberg Aasland7244c002021-04-27 01:16:46 +0200520 .. audit-event:: sqlite3.enable_load_extension connection,enabled sqlite3.enable_load_extension
521
R David Murray6db23352012-09-30 20:44:43 -0400522 .. versionadded:: 3.2
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +0200523
Erlend Egeberg Aasland7244c002021-04-27 01:16:46 +0200524 .. versionchanged:: 3.10
525 Added the ``sqlite3.enable_load_extension`` auditing event.
526
R David Murray6db23352012-09-30 20:44:43 -0400527 .. literalinclude:: ../includes/sqlite3/load_extension.py
Georg Brandl67b21b72010-08-17 15:07:14 +0000528
R David Murray6db23352012-09-30 20:44:43 -0400529 .. method:: load_extension(path)
Gerhard Häringf9cee222010-03-05 15:20:03 +0000530
R David Murray6db23352012-09-30 20:44:43 -0400531 This routine loads a SQLite extension from a shared library. You have to
532 enable extension loading with :meth:`enable_load_extension` before you can
533 use this routine.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000534
R David Murray6db23352012-09-30 20:44:43 -0400535 Loadable extensions are disabled by default. See [#f1]_.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000536
Erlend Egeberg Aasland7244c002021-04-27 01:16:46 +0200537 .. audit-event:: sqlite3.load_extension connection,path sqlite3.load_extension
538
R David Murray6db23352012-09-30 20:44:43 -0400539 .. versionadded:: 3.2
Gerhard Häringe0941c52010-10-03 21:47:06 +0000540
Erlend Egeberg Aasland7244c002021-04-27 01:16:46 +0200541 .. versionchanged:: 3.10
542 Added the ``sqlite3.load_extension`` auditing event.
543
R David Murray6db23352012-09-30 20:44:43 -0400544 .. attribute:: row_factory
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +0200545
R David Murray6db23352012-09-30 20:44:43 -0400546 You can change this attribute to a callable that accepts the cursor and the
547 original row as a tuple and will return the real result row. This way, you can
548 implement more advanced ways of returning results, such as returning an object
549 that can also access columns by name.
Georg Brandl116aa622007-08-15 14:28:22 +0000550
R David Murray6db23352012-09-30 20:44:43 -0400551 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000552
R David Murray6db23352012-09-30 20:44:43 -0400553 .. literalinclude:: ../includes/sqlite3/row_factory.py
Georg Brandl116aa622007-08-15 14:28:22 +0000554
R David Murray6db23352012-09-30 20:44:43 -0400555 If returning a tuple doesn't suffice and you want name-based access to
556 columns, you should consider setting :attr:`row_factory` to the
557 highly-optimized :class:`sqlite3.Row` type. :class:`Row` provides both
558 index-based and case-insensitive name-based access to columns with almost no
559 memory overhead. It will probably be better than your own custom
560 dictionary-based approach or even a db_row based solution.
Georg Brandl116aa622007-08-15 14:28:22 +0000561
R David Murray6db23352012-09-30 20:44:43 -0400562 .. XXX what's a db_row-based solution?
Georg Brandl116aa622007-08-15 14:28:22 +0000563
Georg Brandl116aa622007-08-15 14:28:22 +0000564
R David Murray6db23352012-09-30 20:44:43 -0400565 .. attribute:: text_factory
Georg Brandl116aa622007-08-15 14:28:22 +0000566
R David Murray6db23352012-09-30 20:44:43 -0400567 Using this attribute you can control what objects are returned for the ``TEXT``
568 data type. By default, this attribute is set to :class:`str` and the
Miss Islington (bot)258c5fb2021-10-05 14:04:27 -0700569 :mod:`sqlite3` module will return :class:`str` objects for ``TEXT``.
570 If you want to return :class:`bytes` instead, you can set it to :class:`bytes`.
Georg Brandl116aa622007-08-15 14:28:22 +0000571
R David Murray6db23352012-09-30 20:44:43 -0400572 You can also set it to any other callable that accepts a single bytestring
573 parameter and returns the resulting object.
Georg Brandl116aa622007-08-15 14:28:22 +0000574
R David Murray6db23352012-09-30 20:44:43 -0400575 See the following example code for illustration:
Georg Brandl116aa622007-08-15 14:28:22 +0000576
R David Murray6db23352012-09-30 20:44:43 -0400577 .. literalinclude:: ../includes/sqlite3/text_factory.py
Georg Brandl116aa622007-08-15 14:28:22 +0000578
579
R David Murray6db23352012-09-30 20:44:43 -0400580 .. attribute:: total_changes
Georg Brandl116aa622007-08-15 14:28:22 +0000581
R David Murray6db23352012-09-30 20:44:43 -0400582 Returns the total number of database rows that have been modified, inserted, or
583 deleted since the database connection was opened.
Georg Brandl116aa622007-08-15 14:28:22 +0000584
585
Berker Peksag557a0632016-03-27 18:46:18 +0300586 .. method:: iterdump
Christian Heimesbbe741d2008-03-28 10:53:29 +0000587
R David Murray6db23352012-09-30 20:44:43 -0400588 Returns an iterator to dump the database in an SQL text format. Useful when
589 saving an in-memory database for later restoration. This function provides
590 the same capabilities as the :kbd:`.dump` command in the :program:`sqlite3`
591 shell.
Christian Heimesbbe741d2008-03-28 10:53:29 +0000592
R David Murray6db23352012-09-30 20:44:43 -0400593 Example::
Christian Heimesbbe741d2008-03-28 10:53:29 +0000594
R David Murray6db23352012-09-30 20:44:43 -0400595 # Convert file existing_db.db to SQL dump file dump.sql
Berker Peksag557a0632016-03-27 18:46:18 +0300596 import sqlite3
Christian Heimesbbe741d2008-03-28 10:53:29 +0000597
R David Murray6db23352012-09-30 20:44:43 -0400598 con = sqlite3.connect('existing_db.db')
599 with open('dump.sql', 'w') as f:
600 for line in con.iterdump():
601 f.write('%s\n' % line)
Xtreak287b84d2019-05-20 03:22:20 +0530602 con.close()
Christian Heimesbbe741d2008-03-28 10:53:29 +0000603
604
Erlend Egeberg Aaslandabba83b2020-12-27 23:35:17 +0100605 .. method:: backup(target, *, pages=-1, progress=None, name="main", sleep=0.250)
Emanuele Gaifasd7aed412018-03-10 23:08:31 +0100606
607 This method makes a backup of a SQLite database even while it's being accessed
608 by other clients, or concurrently by the same connection. The copy will be
609 written into the mandatory argument *target*, that must be another
610 :class:`Connection` instance.
611
612 By default, or when *pages* is either ``0`` or a negative integer, the entire
613 database is copied in a single step; otherwise the method performs a loop
614 copying up to *pages* pages at a time.
615
616 If *progress* is specified, it must either be ``None`` or a callable object that
617 will be executed at each iteration with three integer arguments, respectively
618 the *status* of the last iteration, the *remaining* number of pages still to be
619 copied and the *total* number of pages.
620
621 The *name* argument specifies the database name that will be copied: it must be
622 a string containing either ``"main"``, the default, to indicate the main
623 database, ``"temp"`` to indicate the temporary database or the name specified
624 after the ``AS`` keyword in an ``ATTACH DATABASE`` statement for an attached
625 database.
626
627 The *sleep* argument specifies the number of seconds to sleep by between
628 successive attempts to backup remaining pages, can be specified either as an
629 integer or a floating point value.
630
631 Example 1, copy an existing database into another::
632
633 import sqlite3
634
635 def progress(status, remaining, total):
636 print(f'Copied {total-remaining} of {total} pages...')
637
638 con = sqlite3.connect('existing_db.db')
Xtreak287b84d2019-05-20 03:22:20 +0530639 bck = sqlite3.connect('backup.db')
640 with bck:
Emanuele Gaifasd7aed412018-03-10 23:08:31 +0100641 con.backup(bck, pages=1, progress=progress)
Xtreak287b84d2019-05-20 03:22:20 +0530642 bck.close()
643 con.close()
Emanuele Gaifasd7aed412018-03-10 23:08:31 +0100644
645 Example 2, copy an existing database into a transient copy::
646
647 import sqlite3
648
649 source = sqlite3.connect('existing_db.db')
650 dest = sqlite3.connect(':memory:')
651 source.backup(dest)
652
Emanuele Gaifasd7aed412018-03-10 23:08:31 +0100653 .. versionadded:: 3.7
654
655
Georg Brandl116aa622007-08-15 14:28:22 +0000656.. _sqlite3-cursor-objects:
657
658Cursor Objects
659--------------
660
Georg Brandl96115fb22010-10-17 09:33:24 +0000661.. class:: Cursor
Georg Brandl116aa622007-08-15 14:28:22 +0000662
Georg Brandl96115fb22010-10-17 09:33:24 +0000663 A :class:`Cursor` instance has the following attributes and methods.
Georg Brandl116aa622007-08-15 14:28:22 +0000664
Serhiy Storchaka913876d2018-10-28 13:41:26 +0200665 .. index:: single: ? (question mark); in SQL statements
666 .. index:: single: : (colon); in SQL statements
667
Berker Peksagc4154402016-06-12 13:41:47 +0300668 .. method:: execute(sql[, parameters])
Georg Brandl116aa622007-08-15 14:28:22 +0000669
Erlend Egeberg Aasland3386ca02021-04-14 14:28:55 +0200670 Executes an SQL statement. Values may be bound to the statement using
671 :ref:`placeholders <sqlite3-placeholders>`.
Georg Brandl116aa622007-08-15 14:28:22 +0000672
R David Murray6db23352012-09-30 20:44:43 -0400673 :meth:`execute` will only execute a single SQL statement. If you try to execute
Berker Peksag7d92f892016-08-25 00:50:24 +0300674 more than one statement with it, it will raise a :exc:`.Warning`. Use
R David Murray6db23352012-09-30 20:44:43 -0400675 :meth:`executescript` if you want to execute multiple SQL statements with one
676 call.
Georg Brandl116aa622007-08-15 14:28:22 +0000677
678
R David Murray6db23352012-09-30 20:44:43 -0400679 .. method:: executemany(sql, seq_of_parameters)
Georg Brandl116aa622007-08-15 14:28:22 +0000680
Erlend Egeberg Aasland3386ca02021-04-14 14:28:55 +0200681 Executes a :ref:`parameterized <sqlite3-placeholders>` SQL command
682 against all parameter sequences or mappings found in the sequence
683 *seq_of_parameters*. The :mod:`sqlite3` module also allows using an
684 :term:`iterator` yielding parameters instead of a sequence.
Georg Brandl116aa622007-08-15 14:28:22 +0000685
R David Murray6db23352012-09-30 20:44:43 -0400686 .. literalinclude:: ../includes/sqlite3/executemany_1.py
Georg Brandl116aa622007-08-15 14:28:22 +0000687
R David Murray6db23352012-09-30 20:44:43 -0400688 Here's a shorter example using a :term:`generator`:
Georg Brandl116aa622007-08-15 14:28:22 +0000689
R David Murray6db23352012-09-30 20:44:43 -0400690 .. literalinclude:: ../includes/sqlite3/executemany_2.py
Georg Brandl116aa622007-08-15 14:28:22 +0000691
692
R David Murray6db23352012-09-30 20:44:43 -0400693 .. method:: executescript(sql_script)
Georg Brandl116aa622007-08-15 14:28:22 +0000694
R David Murray6db23352012-09-30 20:44:43 -0400695 This is a nonstandard convenience method for executing multiple SQL statements
696 at once. It issues a ``COMMIT`` statement first, then executes the SQL script it
Miss Islington (bot)1f483c02021-05-19 00:37:33 -0700697 gets as a parameter. This method disregards :attr:`isolation_level`; any
Miss Islington (bot)3048b8b2021-07-14 15:22:50 -0700698 transaction control must be added to *sql_script*.
Georg Brandl116aa622007-08-15 14:28:22 +0000699
Berker Peksagc4154402016-06-12 13:41:47 +0300700 *sql_script* can be an instance of :class:`str`.
Georg Brandl116aa622007-08-15 14:28:22 +0000701
R David Murray6db23352012-09-30 20:44:43 -0400702 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000703
R David Murray6db23352012-09-30 20:44:43 -0400704 .. literalinclude:: ../includes/sqlite3/executescript.py
Georg Brandl116aa622007-08-15 14:28:22 +0000705
706
R David Murray6db23352012-09-30 20:44:43 -0400707 .. method:: fetchone()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000708
R David Murray6db23352012-09-30 20:44:43 -0400709 Fetches the next row of a query result set, returning a single sequence,
710 or :const:`None` when no more data is available.
Christian Heimesfdab48e2008-01-20 09:06:41 +0000711
712
R David Murray6db23352012-09-30 20:44:43 -0400713 .. method:: fetchmany(size=cursor.arraysize)
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000714
R David Murray6db23352012-09-30 20:44:43 -0400715 Fetches the next set of rows of a query result, returning a list. An empty
716 list is returned when no more rows are available.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000717
R David Murray6db23352012-09-30 20:44:43 -0400718 The number of rows to fetch per call is specified by the *size* parameter.
719 If it is not given, the cursor's arraysize determines the number of rows
720 to be fetched. The method should try to fetch as many rows as indicated by
721 the size parameter. If this is not possible due to the specified number of
722 rows not being available, fewer rows may be returned.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000723
R David Murray6db23352012-09-30 20:44:43 -0400724 Note there are performance considerations involved with the *size* parameter.
725 For optimal performance, it is usually best to use the arraysize attribute.
726 If the *size* parameter is used, then it is best for it to retain the same
727 value from one :meth:`fetchmany` call to the next.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000728
R David Murray6db23352012-09-30 20:44:43 -0400729 .. method:: fetchall()
Christian Heimesfdab48e2008-01-20 09:06:41 +0000730
R David Murray6db23352012-09-30 20:44:43 -0400731 Fetches all (remaining) rows of a query result, returning a list. Note that
732 the cursor's arraysize attribute can affect the performance of this operation.
733 An empty list is returned when no rows are available.
Christian Heimesfdab48e2008-01-20 09:06:41 +0000734
Berker Peksagf70fe6f2016-03-27 21:51:02 +0300735 .. method:: close()
736
737 Close the cursor now (rather than whenever ``__del__`` is called).
738
Berker Peksaged789f92016-08-25 00:45:07 +0300739 The cursor will be unusable from this point forward; a :exc:`ProgrammingError`
Berker Peksagf70fe6f2016-03-27 21:51:02 +0300740 exception will be raised if any operation is attempted with the cursor.
Christian Heimesfdab48e2008-01-20 09:06:41 +0000741
Miss Islington (bot)1d88b2b2021-10-28 12:57:14 -0700742 .. method:: setinputsizes(sizes)
743
744 Required by the DB-API. Is a no-op in :mod:`sqlite3`.
745
746 .. method:: setoutputsize(size [, column])
747
748 Required by the DB-API. Is a no-op in :mod:`sqlite3`.
749
R David Murray6db23352012-09-30 20:44:43 -0400750 .. attribute:: rowcount
Georg Brandl116aa622007-08-15 14:28:22 +0000751
R David Murray6db23352012-09-30 20:44:43 -0400752 Although the :class:`Cursor` class of the :mod:`sqlite3` module implements this
753 attribute, the database engine's own support for the determination of "rows
754 affected"/"rows selected" is quirky.
Georg Brandl116aa622007-08-15 14:28:22 +0000755
R David Murray6db23352012-09-30 20:44:43 -0400756 For :meth:`executemany` statements, the number of modifications are summed up
757 into :attr:`rowcount`.
Georg Brandl116aa622007-08-15 14:28:22 +0000758
R David Murray6db23352012-09-30 20:44:43 -0400759 As required by the Python DB API Spec, the :attr:`rowcount` attribute "is -1 in
760 case no ``executeXX()`` has been performed on the cursor or the rowcount of the
761 last operation is not determinable by the interface". This includes ``SELECT``
762 statements because we cannot determine the number of rows a query produced
763 until all rows were fetched.
Georg Brandl116aa622007-08-15 14:28:22 +0000764
R David Murray6db23352012-09-30 20:44:43 -0400765 .. attribute:: lastrowid
Gerhard Häringd3372792008-03-29 19:13:55 +0000766
R David Murray6db23352012-09-30 20:44:43 -0400767 This read-only attribute provides the rowid of the last modified row. It is
Berker Peksage0b70cd2016-06-14 15:25:36 +0300768 only set if you issued an ``INSERT`` or a ``REPLACE`` statement using the
769 :meth:`execute` method. For operations other than ``INSERT`` or
770 ``REPLACE`` or when :meth:`executemany` is called, :attr:`lastrowid` is
771 set to :const:`None`.
772
773 If the ``INSERT`` or ``REPLACE`` statement failed to insert the previous
774 successful rowid is returned.
775
776 .. versionchanged:: 3.6
777 Added support for the ``REPLACE`` statement.
Georg Brandl116aa622007-08-15 14:28:22 +0000778
csabella02e12132017-04-04 01:16:14 -0400779 .. attribute:: arraysize
780
781 Read/write attribute that controls the number of rows returned by :meth:`fetchmany`.
782 The default value is 1 which means a single row would be fetched per call.
783
R David Murray6db23352012-09-30 20:44:43 -0400784 .. attribute:: description
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000785
R David Murray6db23352012-09-30 20:44:43 -0400786 This read-only attribute provides the column names of the last query. To
787 remain compatible with the Python DB API, it returns a 7-tuple for each
788 column where the last six items of each tuple are :const:`None`.
Georg Brandl48310cd2009-01-03 21:18:54 +0000789
R David Murray6db23352012-09-30 20:44:43 -0400790 It is set for ``SELECT`` statements without any matching rows as well.
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000791
Ezio Melotti62564db2016-03-18 20:10:36 +0200792 .. attribute:: connection
793
794 This read-only attribute provides the SQLite database :class:`Connection`
795 used by the :class:`Cursor` object. A :class:`Cursor` object created by
796 calling :meth:`con.cursor() <Connection.cursor>` will have a
797 :attr:`connection` attribute that refers to *con*::
798
799 >>> con = sqlite3.connect(":memory:")
800 >>> cur = con.cursor()
801 >>> cur.connection == con
802 True
803
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000804.. _sqlite3-row-objects:
805
806Row Objects
807-----------
808
809.. class:: Row
810
811 A :class:`Row` instance serves as a highly optimized
Georg Brandl48310cd2009-01-03 21:18:54 +0000812 :attr:`~Connection.row_factory` for :class:`Connection` objects.
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000813 It tries to mimic a tuple in most of its features.
814
815 It supports mapping access by column name and index, iteration,
816 representation, equality testing and :func:`len`.
817
818 If two :class:`Row` objects have exactly the same columns and their
819 members are equal, they compare equal.
Georg Brandl48310cd2009-01-03 21:18:54 +0000820
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000821 .. method:: keys
822
R David Murray092135e2014-06-05 15:16:38 -0400823 This method returns a list of column names. Immediately after a query,
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000824 it is the first member of each tuple in :attr:`Cursor.description`.
825
Serhiy Storchaka72e731c2015-03-31 13:33:11 +0300826 .. versionchanged:: 3.5
827 Added support of slicing.
828
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000829Let's assume we initialize a table as in the example given above::
830
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +0100831 con = sqlite3.connect(":memory:")
832 cur = con.cursor()
833 cur.execute('''create table stocks
Senthil Kumaran946eb862011-07-03 10:17:22 -0700834 (date text, trans text, symbol text,
835 qty real, price real)''')
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +0100836 cur.execute("""insert into stocks
837 values ('2006-01-05','BUY','RHAT',100,35.14)""")
838 con.commit()
839 cur.close()
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000840
841Now we plug :class:`Row` in::
842
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +0100843 >>> con.row_factory = sqlite3.Row
844 >>> cur = con.cursor()
845 >>> cur.execute('select * from stocks')
Senthil Kumaran946eb862011-07-03 10:17:22 -0700846 <sqlite3.Cursor object at 0x7f4e7dd8fa80>
Erlend Egeberg Aasland40d1b832021-03-04 16:46:14 +0100847 >>> r = cur.fetchone()
Senthil Kumaran946eb862011-07-03 10:17:22 -0700848 >>> type(r)
849 <class 'sqlite3.Row'>
850 >>> tuple(r)
851 ('2006-01-05', 'BUY', 'RHAT', 100.0, 35.14)
852 >>> len(r)
853 5
854 >>> r[2]
855 'RHAT'
856 >>> r.keys()
857 ['date', 'trans', 'symbol', 'qty', 'price']
858 >>> r['qty']
859 100.0
860 >>> for member in r:
861 ... print(member)
862 ...
863 2006-01-05
864 BUY
865 RHAT
866 100.0
867 35.14
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000868
869
Berker Peksaged789f92016-08-25 00:45:07 +0300870.. _sqlite3-exceptions:
871
872Exceptions
873----------
874
875.. exception:: Warning
876
877 A subclass of :exc:`Exception`.
878
879.. exception:: Error
880
881 The base class of the other exceptions in this module. It is a subclass
882 of :exc:`Exception`.
883
884.. exception:: DatabaseError
885
886 Exception raised for errors that are related to the database.
887
888.. exception:: IntegrityError
889
890 Exception raised when the relational integrity of the database is affected,
891 e.g. a foreign key check fails. It is a subclass of :exc:`DatabaseError`.
892
893.. exception:: ProgrammingError
894
895 Exception raised for programming errors, e.g. table not found or already
896 exists, syntax error in the SQL statement, wrong number of parameters
897 specified, etc. It is a subclass of :exc:`DatabaseError`.
898
Zackery Spytz71ede002018-06-13 03:09:31 -0600899.. exception:: OperationalError
900
901 Exception raised for errors that are related to the database's operation
902 and not necessarily under the control of the programmer, e.g. an unexpected
903 disconnect occurs, the data source name is not found, a transaction could
904 not be processed, etc. It is a subclass of :exc:`DatabaseError`.
905
Marcin Niemirabc9aa812018-07-08 14:02:58 +0200906.. exception:: NotSupportedError
907
908 Exception raised in case a method or database API was used which is not
909 supported by the database, e.g. calling the :meth:`~Connection.rollback`
910 method on a connection that does not support transaction or has
911 transactions turned off. It is a subclass of :exc:`DatabaseError`.
912
Berker Peksaged789f92016-08-25 00:45:07 +0300913
Georg Brandl116aa622007-08-15 14:28:22 +0000914.. _sqlite3-types:
915
916SQLite and Python types
917-----------------------
918
919
920Introduction
921^^^^^^^^^^^^
922
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000923SQLite natively supports the following types: ``NULL``, ``INTEGER``,
924``REAL``, ``TEXT``, ``BLOB``.
Georg Brandl116aa622007-08-15 14:28:22 +0000925
926The following Python types can thus be sent to SQLite without any problem:
927
Georg Brandlf6945182008-02-01 11:56:49 +0000928+-------------------------------+-------------+
929| Python type | SQLite type |
930+===============================+=============+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000931| :const:`None` | ``NULL`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000932+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000933| :class:`int` | ``INTEGER`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000934+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000935| :class:`float` | ``REAL`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000936+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000937| :class:`str` | ``TEXT`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000938+-------------------------------+-------------+
Antoine Pitrouf06917e2010-02-02 23:00:29 +0000939| :class:`bytes` | ``BLOB`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000940+-------------------------------+-------------+
Georg Brandl116aa622007-08-15 14:28:22 +0000941
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000942
Georg Brandl116aa622007-08-15 14:28:22 +0000943This is how SQLite types are converted to Python types by default:
944
Zachary Ware9d085622014-04-01 12:21:56 -0500945+-------------+----------------------------------------------+
946| SQLite type | Python type |
947+=============+==============================================+
948| ``NULL`` | :const:`None` |
949+-------------+----------------------------------------------+
950| ``INTEGER`` | :class:`int` |
951+-------------+----------------------------------------------+
952| ``REAL`` | :class:`float` |
953+-------------+----------------------------------------------+
954| ``TEXT`` | depends on :attr:`~Connection.text_factory`, |
955| | :class:`str` by default |
956+-------------+----------------------------------------------+
957| ``BLOB`` | :class:`bytes` |
958+-------------+----------------------------------------------+
Georg Brandl116aa622007-08-15 14:28:22 +0000959
960The type system of the :mod:`sqlite3` module is extensible in two ways: you can
961store additional Python types in a SQLite database via object adaptation, and
962you can let the :mod:`sqlite3` module convert SQLite types to different Python
963types via converters.
964
965
966Using adapters to store additional Python types in SQLite databases
967^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
968
969As described before, SQLite supports only a limited set of types natively. To
970use other Python types with SQLite, you must **adapt** them to one of the
Georg Brandl5c106642007-11-29 17:41:05 +0000971sqlite3 module's supported types for SQLite: one of NoneType, int, float,
Antoine Pitrouf06917e2010-02-02 23:00:29 +0000972str, bytes.
Georg Brandl116aa622007-08-15 14:28:22 +0000973
Georg Brandl116aa622007-08-15 14:28:22 +0000974There are two ways to enable the :mod:`sqlite3` module to adapt a custom Python
975type to one of the supported ones.
976
977
978Letting your object adapt itself
979""""""""""""""""""""""""""""""""
980
981This is a good approach if you write the class yourself. Let's suppose you have
982a class like this::
983
Éric Araujo28053fb2010-11-22 03:09:19 +0000984 class Point:
Georg Brandl116aa622007-08-15 14:28:22 +0000985 def __init__(self, x, y):
986 self.x, self.y = x, y
987
988Now you want to store the point in a single SQLite column. First you'll have to
Naglis441416c2020-05-06 19:51:43 +0000989choose one of the supported types to be used for representing the point.
Georg Brandl116aa622007-08-15 14:28:22 +0000990Let's just use str and separate the coordinates using a semicolon. Then you need
991to give your class a method ``__conform__(self, protocol)`` which must return
992the converted value. The parameter *protocol* will be :class:`PrepareProtocol`.
993
994.. literalinclude:: ../includes/sqlite3/adapter_point_1.py
995
996
997Registering an adapter callable
998"""""""""""""""""""""""""""""""
999
1000The other possibility is to create a function that converts the type to the
1001string representation and register the function with :meth:`register_adapter`.
1002
Georg Brandl116aa622007-08-15 14:28:22 +00001003.. literalinclude:: ../includes/sqlite3/adapter_point_2.py
1004
1005The :mod:`sqlite3` module has two default adapters for Python's built-in
1006:class:`datetime.date` and :class:`datetime.datetime` types. Now let's suppose
1007we want to store :class:`datetime.datetime` objects not in ISO representation,
1008but as a Unix timestamp.
1009
1010.. literalinclude:: ../includes/sqlite3/adapter_datetime.py
1011
1012
1013Converting SQLite values to custom Python types
1014^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1015
1016Writing an adapter lets you send custom Python types to SQLite. But to make it
1017really useful we need to make the Python to SQLite to Python roundtrip work.
1018
1019Enter converters.
1020
1021Let's go back to the :class:`Point` class. We stored the x and y coordinates
1022separated via semicolons as strings in SQLite.
1023
1024First, we'll define a converter function that accepts the string as a parameter
1025and constructs a :class:`Point` object from it.
1026
1027.. note::
1028
Zachary Ware9d085622014-04-01 12:21:56 -05001029 Converter functions **always** get called with a :class:`bytes` object, no
1030 matter under which data type you sent the value to SQLite.
Georg Brandl116aa622007-08-15 14:28:22 +00001031
Georg Brandl116aa622007-08-15 14:28:22 +00001032::
1033
1034 def convert_point(s):
Petri Lehtinen1ca93952012-02-15 22:17:21 +02001035 x, y = map(float, s.split(b";"))
Georg Brandl116aa622007-08-15 14:28:22 +00001036 return Point(x, y)
1037
1038Now you need to make the :mod:`sqlite3` module know that what you select from
1039the database is actually a point. There are two ways of doing this:
1040
1041* Implicitly via the declared type
1042
1043* Explicitly via the column name
1044
1045Both ways are described in section :ref:`sqlite3-module-contents`, in the entries
1046for the constants :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`.
1047
1048The following example illustrates both approaches.
1049
1050.. literalinclude:: ../includes/sqlite3/converter_point.py
1051
1052
1053Default adapters and converters
1054^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1055
1056There are default adapters for the date and datetime types in the datetime
1057module. They will be sent as ISO dates/ISO timestamps to SQLite.
1058
1059The default converters are registered under the name "date" for
1060:class:`datetime.date` and under the name "timestamp" for
1061:class:`datetime.datetime`.
1062
1063This way, you can use date/timestamps from Python without any additional
1064fiddling in most cases. The format of the adapters is also compatible with the
1065experimental SQLite date/time functions.
1066
1067The following example demonstrates this.
1068
1069.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py
1070
Petri Lehtinen5f794092013-02-26 21:32:02 +02001071If a timestamp stored in SQLite has a fractional part longer than 6
1072numbers, its value will be truncated to microsecond precision by the
1073timestamp converter.
1074
Miss Islington (bot)8ea665c2021-10-29 13:41:45 -07001075.. note::
1076
1077 The default "timestamp" converter ignores UTC offsets in the database and
1078 always returns a naive :class:`datetime.datetime` object. To preserve UTC
1079 offsets in timestamps, either leave converters disabled, or register an
1080 offset-aware converter with :func:`register_converter`.
Georg Brandl116aa622007-08-15 14:28:22 +00001081
1082.. _sqlite3-controlling-transactions:
1083
1084Controlling Transactions
1085------------------------
1086
Berker Peksaga71fed02018-07-29 12:01:38 +03001087The underlying ``sqlite3`` library operates in ``autocommit`` mode by default,
1088but the Python :mod:`sqlite3` module by default does not.
1089
1090``autocommit`` mode means that statements that modify the database take effect
1091immediately. A ``BEGIN`` or ``SAVEPOINT`` statement disables ``autocommit``
1092mode, and a ``COMMIT``, a ``ROLLBACK``, or a ``RELEASE`` that ends the
1093outermost transaction, turns ``autocommit`` mode back on.
1094
1095The Python :mod:`sqlite3` module by default issues a ``BEGIN`` statement
1096implicitly before a Data Modification Language (DML) statement (i.e.
Berker Peksagab994ed2016-09-11 12:57:15 +03001097``INSERT``/``UPDATE``/``DELETE``/``REPLACE``).
Georg Brandl116aa622007-08-15 14:28:22 +00001098
Berker Peksaga71fed02018-07-29 12:01:38 +03001099You can control which kind of ``BEGIN`` statements :mod:`sqlite3` implicitly
1100executes via the *isolation_level* parameter to the :func:`connect`
Georg Brandl116aa622007-08-15 14:28:22 +00001101call, or via the :attr:`isolation_level` property of connections.
Berker Peksaga71fed02018-07-29 12:01:38 +03001102If you specify no *isolation_level*, a plain ``BEGIN`` is used, which is
1103equivalent to specifying ``DEFERRED``. Other possible values are ``IMMEDIATE``
1104and ``EXCLUSIVE``.
Georg Brandl116aa622007-08-15 14:28:22 +00001105
Berker Peksaga71fed02018-07-29 12:01:38 +03001106You can disable the :mod:`sqlite3` module's implicit transaction management by
1107setting :attr:`isolation_level` to ``None``. This will leave the underlying
1108``sqlite3`` library operating in ``autocommit`` mode. You can then completely
1109control the transaction state by explicitly issuing ``BEGIN``, ``ROLLBACK``,
1110``SAVEPOINT``, and ``RELEASE`` statements in your code.
Berker Peksagfe70d922017-02-26 18:31:12 +03001111
Miss Islington (bot)1f483c02021-05-19 00:37:33 -07001112Note that :meth:`~Cursor.executescript` disregards
1113:attr:`isolation_level`; any transaction control must be added explicitly.
1114
Berker Peksagab994ed2016-09-11 12:57:15 +03001115.. versionchanged:: 3.6
1116 :mod:`sqlite3` used to implicitly commit an open transaction before DDL
1117 statements. This is no longer the case.
Georg Brandl116aa622007-08-15 14:28:22 +00001118
1119
Georg Brandl8a1e4c42009-05-25 21:13:36 +00001120Using :mod:`sqlite3` efficiently
1121--------------------------------
Georg Brandl116aa622007-08-15 14:28:22 +00001122
1123
1124Using shortcut methods
1125^^^^^^^^^^^^^^^^^^^^^^
1126
1127Using the nonstandard :meth:`execute`, :meth:`executemany` and
1128:meth:`executescript` methods of the :class:`Connection` object, your code can
1129be written more concisely because you don't have to create the (often
1130superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
1131objects are created implicitly and these shortcut methods return the cursor
Benjamin Petersonf10a79a2008-10-11 00:49:57 +00001132objects. This way, you can execute a ``SELECT`` statement and iterate over it
Georg Brandl116aa622007-08-15 14:28:22 +00001133directly using only a single call on the :class:`Connection` object.
1134
1135.. literalinclude:: ../includes/sqlite3/shortcut_methods.py
1136
1137
1138Accessing columns by name instead of by index
1139^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1140
Georg Brandl22b34312009-07-26 14:54:51 +00001141One useful feature of the :mod:`sqlite3` module is the built-in
Georg Brandl116aa622007-08-15 14:28:22 +00001142:class:`sqlite3.Row` class designed to be used as a row factory.
1143
1144Rows wrapped with this class can be accessed both by index (like tuples) and
1145case-insensitively by name:
1146
1147.. literalinclude:: ../includes/sqlite3/rowclass.py
1148
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +00001149
1150Using the connection as a context manager
1151^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1152
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +00001153Connection objects can be used as context managers
1154that automatically commit or rollback transactions. In the event of an
1155exception, the transaction is rolled back; otherwise, the transaction is
1156committed:
1157
1158.. literalinclude:: ../includes/sqlite3/ctx_manager.py
Gerhard Häringc34d76c2010-08-06 06:12:05 +00001159
1160
Gerhard Häringe0941c52010-10-03 21:47:06 +00001161.. rubric:: Footnotes
1162
1163.. [#f1] The sqlite3 module is not built with loadable extension support by
Miss Islington (bot)1493e1a2021-09-23 03:25:31 -07001164 default, because some platforms (notably macOS) have SQLite
Senthil Kumaran946eb862011-07-03 10:17:22 -07001165 libraries which are compiled without this feature. To get loadable
Victor Stinner85918e42021-04-12 23:27:35 +02001166 extension support, you must pass the
1167 :option:`--enable-loadable-sqlite-extensions` option to configure.