blob: e0411fed2f9c3b272e2ef07d00578aed05aed68e [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
21compliant with the DB-API 2.0 specification described by :pep:`249`.
Georg Brandl116aa622007-08-15 14:28:22 +000022
23To use the module, you must first create a :class:`Connection` object that
24represents the database. Here the data will be stored in the
Petri Lehtinen9f74c6c2013-02-23 19:26:56 +010025:file:`example.db` file::
Georg Brandl116aa622007-08-15 14:28:22 +000026
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +020027 import sqlite3
Petri Lehtinen9f74c6c2013-02-23 19:26:56 +010028 conn = sqlite3.connect('example.db')
Georg Brandl116aa622007-08-15 14:28:22 +000029
30You can also supply the special name ``:memory:`` to create a database in RAM.
31
32Once you have a :class:`Connection`, you can create a :class:`Cursor` object
Benjamin Petersonf10a79a2008-10-11 00:49:57 +000033and call its :meth:`~Cursor.execute` method to perform SQL commands::
Georg Brandl116aa622007-08-15 14:28:22 +000034
35 c = conn.cursor()
36
37 # Create table
Zachary Ware9d085622014-04-01 12:21:56 -050038 c.execute('''CREATE TABLE stocks
39 (date text, trans text, symbol text, qty real, price real)''')
Georg Brandl116aa622007-08-15 14:28:22 +000040
41 # Insert a row of data
Zachary Ware9d085622014-04-01 12:21:56 -050042 c.execute("INSERT INTO stocks VALUES ('2006-01-05','BUY','RHAT',100,35.14)")
Georg Brandl116aa622007-08-15 14:28:22 +000043
44 # Save (commit) the changes
45 conn.commit()
46
Zachary Ware9d085622014-04-01 12:21:56 -050047 # We can also close the connection if we are done with it.
48 # Just be sure any changes have been committed or they will be lost.
49 conn.close()
50
51The data you've saved is persistent and is available in subsequent sessions::
52
53 import sqlite3
54 conn = sqlite3.connect('example.db')
55 c = conn.cursor()
Georg Brandl116aa622007-08-15 14:28:22 +000056
57Usually your SQL operations will need to use values from Python variables. You
58shouldn't assemble your query using Python's string operations because doing so
Zachary Ware9d085622014-04-01 12:21:56 -050059is insecure; it makes your program vulnerable to an SQL injection attack
Serhiy Storchaka6dff0202016-05-07 10:49:07 +030060(see https://xkcd.com/327/ for humorous example of what can go wrong).
Georg Brandl116aa622007-08-15 14:28:22 +000061
62Instead, use the DB-API's parameter substitution. Put ``?`` as a placeholder
63wherever you want to use a value, and then provide a tuple of values as the
Georg Brandl8a1e4c42009-05-25 21:13:36 +000064second argument to the cursor's :meth:`~Cursor.execute` method. (Other database
65modules may use a different placeholder, such as ``%s`` or ``:1``.) For
66example::
Georg Brandl116aa622007-08-15 14:28:22 +000067
68 # Never do this -- insecure!
Zachary Ware9d085622014-04-01 12:21:56 -050069 symbol = 'RHAT'
70 c.execute("SELECT * FROM stocks WHERE symbol = '%s'" % symbol)
Georg Brandl116aa622007-08-15 14:28:22 +000071
72 # Do this instead
Zachary Ware9d085622014-04-01 12:21:56 -050073 t = ('RHAT',)
74 c.execute('SELECT * FROM stocks WHERE symbol=?', t)
75 print(c.fetchone())
Georg Brandl116aa622007-08-15 14:28:22 +000076
Zachary Ware9d085622014-04-01 12:21:56 -050077 # Larger example that inserts many records at a time
78 purchases = [('2006-03-28', 'BUY', 'IBM', 1000, 45.00),
79 ('2006-04-05', 'BUY', 'MSFT', 1000, 72.00),
80 ('2006-04-06', 'SELL', 'IBM', 500, 53.00),
81 ]
82 c.executemany('INSERT INTO stocks VALUES (?,?,?,?,?)', purchases)
Georg Brandl116aa622007-08-15 14:28:22 +000083
Georg Brandl9afde1c2007-11-01 20:32:30 +000084To retrieve data after executing a SELECT statement, you can either treat the
Benjamin Petersonf10a79a2008-10-11 00:49:57 +000085cursor as an :term:`iterator`, call the cursor's :meth:`~Cursor.fetchone` method to
86retrieve a single matching row, or call :meth:`~Cursor.fetchall` to get a list of the
Georg Brandl9afde1c2007-11-01 20:32:30 +000087matching rows.
Georg Brandl116aa622007-08-15 14:28:22 +000088
89This example uses the iterator form::
90
Zachary Ware9d085622014-04-01 12:21:56 -050091 >>> for row in c.execute('SELECT * FROM stocks ORDER BY price'):
92 print(row)
93
Ezio Melottib5845052009-09-13 05:49:25 +000094 ('2006-01-05', 'BUY', 'RHAT', 100, 35.14)
95 ('2006-03-28', 'BUY', 'IBM', 1000, 45.0)
96 ('2006-04-06', 'SELL', 'IBM', 500, 53.0)
Zachary Ware9d085622014-04-01 12:21:56 -050097 ('2006-04-05', 'BUY', 'MSFT', 1000, 72.0)
Georg Brandl116aa622007-08-15 14:28:22 +000098
99
100.. seealso::
101
Benjamin Peterson216e47d2014-01-16 09:52:38 -0500102 https://github.com/ghaering/pysqlite
Georg Brandl8a1e4c42009-05-25 21:13:36 +0000103 The pysqlite web page -- sqlite3 is developed externally under the name
104 "pysqlite".
Georg Brandl116aa622007-08-15 14:28:22 +0000105
Serhiy Storchaka6dff0202016-05-07 10:49:07 +0300106 https://www.sqlite.org
Georg Brandl8a1e4c42009-05-25 21:13:36 +0000107 The SQLite web page; the documentation describes the syntax and the
108 available data types for the supported SQL dialect.
Georg Brandl116aa622007-08-15 14:28:22 +0000109
Sanyam Khurana1b4587a2017-12-06 22:09:33 +0530110 https://www.w3schools.com/sql/
Zachary Ware9d085622014-04-01 12:21:56 -0500111 Tutorial, reference and examples for learning SQL syntax.
112
Georg Brandl116aa622007-08-15 14:28:22 +0000113 :pep:`249` - Database API Specification 2.0
114 PEP written by Marc-André Lemburg.
115
116
117.. _sqlite3-module-contents:
118
119Module functions and constants
120------------------------------
121
122
R David Murray3f7beb92013-01-10 20:18:21 -0500123.. data:: version
124
125 The version number of this module, as a string. This is not the version of
126 the SQLite library.
127
128
129.. data:: version_info
130
131 The version number of this module, as a tuple of integers. This is not the
132 version of the SQLite library.
133
134
135.. data:: sqlite_version
136
137 The version number of the run-time SQLite library, as a string.
138
139
140.. data:: sqlite_version_info
141
142 The version number of the run-time SQLite library, as a tuple of integers.
143
144
Georg Brandl116aa622007-08-15 14:28:22 +0000145.. data:: PARSE_DECLTYPES
146
147 This constant is meant to be used with the *detect_types* parameter of the
148 :func:`connect` function.
149
150 Setting it makes the :mod:`sqlite3` module parse the declared type for each
Christian Heimes81ee3ef2008-05-04 22:42:01 +0000151 column it returns. It will parse out the first word of the declared type,
152 i. e. for "integer primary key", it will parse out "integer", or for
153 "number(10)" it will parse out "number". Then for that column, it will look
154 into the converters dictionary and use the converter function registered for
155 that type there.
Georg Brandl116aa622007-08-15 14:28:22 +0000156
157
158.. data:: PARSE_COLNAMES
159
160 This constant is meant to be used with the *detect_types* parameter of the
161 :func:`connect` function.
162
163 Setting this makes the SQLite interface parse the column name for each column it
164 returns. It will look for a string formed [mytype] in there, and then decide
165 that 'mytype' is the type of the column. It will try to find an entry of
166 'mytype' in the converters dictionary and then use the converter function found
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000167 there to return the value. The column name found in :attr:`Cursor.description`
Georg Brandl116aa622007-08-15 14:28:22 +0000168 is only the first word of the column name, i. e. if you use something like
169 ``'as "x [datetime]"'`` in your SQL, then we will parse out everything until the
170 first blank for the column name: the column name would simply be "x".
171
172
Antoine Pitrou902fc8b2013-02-10 00:02:44 +0100173.. function:: connect(database[, timeout, detect_types, isolation_level, check_same_thread, factory, cached_statements, uri])
Georg Brandl116aa622007-08-15 14:28:22 +0000174
Anders Lorentsena22a1272017-11-07 01:47:43 +0100175 Opens a connection to the SQLite database file *database*. By default returns a
176 :class:`Connection` object, unless a custom *factory* is given.
177
178 *database* is a :term:`path-like object` giving the pathname (absolute or
179 relative to the current working directory) of the database file to be opened.
180 You can use ``":memory:"`` to open a database connection to a database that
181 resides in RAM instead of on disk.
Georg Brandl116aa622007-08-15 14:28:22 +0000182
183 When a database is accessed by multiple connections, and one of the processes
184 modifies the database, the SQLite database is locked until that transaction is
185 committed. The *timeout* parameter specifies how long the connection should wait
186 for the lock to go away until raising an exception. The default for the timeout
187 parameter is 5.0 (five seconds).
188
189 For the *isolation_level* parameter, please see the
Berker Peksaga1bc2462016-09-07 04:02:41 +0300190 :attr:`~Connection.isolation_level` property of :class:`Connection` objects.
Georg Brandl116aa622007-08-15 14:28:22 +0000191
Georg Brandl3c127112013-10-06 12:38:44 +0200192 SQLite natively supports only the types TEXT, INTEGER, REAL, BLOB and NULL. If
Georg Brandl116aa622007-08-15 14:28:22 +0000193 you want to use other types you must add support for them yourself. The
194 *detect_types* parameter and the using custom **converters** registered with the
195 module-level :func:`register_converter` function allow you to easily do that.
196
197 *detect_types* defaults to 0 (i. e. off, no type detection), you can set it to
198 any combination of :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES` to turn
199 type detection on.
200
Senthil Kumaran7ee91942016-06-03 00:03:48 -0700201 By default, *check_same_thread* is :const:`True` and only the creating thread may
202 use the connection. If set :const:`False`, the returned connection may be shared
203 across multiple threads. When using multiple threads with the same connection
204 writing operations should be serialized by the user to avoid data corruption.
205
Georg Brandl116aa622007-08-15 14:28:22 +0000206 By default, the :mod:`sqlite3` module uses its :class:`Connection` class for the
207 connect call. You can, however, subclass the :class:`Connection` class and make
208 :func:`connect` use your class instead by providing your class for the *factory*
209 parameter.
210
211 Consult the section :ref:`sqlite3-types` of this manual for details.
212
213 The :mod:`sqlite3` module internally uses a statement cache to avoid SQL parsing
214 overhead. If you want to explicitly set the number of statements that are cached
215 for the connection, you can set the *cached_statements* parameter. The currently
216 implemented default is to cache 100 statements.
217
Antoine Pitrou902fc8b2013-02-10 00:02:44 +0100218 If *uri* is true, *database* is interpreted as a URI. This allows you
219 to specify options. For example, to open a database in read-only mode
220 you can use::
221
222 db = sqlite3.connect('file:path/to/database?mode=ro', uri=True)
223
224 More information about this feature, including a list of recognized options, can
Serhiy Storchaka6dff0202016-05-07 10:49:07 +0300225 be found in the `SQLite URI documentation <https://www.sqlite.org/uri.html>`_.
Antoine Pitrou902fc8b2013-02-10 00:02:44 +0100226
Steve Dower60419a72019-06-24 08:42:54 -0700227 .. audit-event:: sqlite3.connect "database"
228
Antoine Pitrou902fc8b2013-02-10 00:02:44 +0100229 .. versionchanged:: 3.4
230 Added the *uri* parameter.
231
Anders Lorentsena22a1272017-11-07 01:47:43 +0100232 .. versionchanged:: 3.7
233 *database* can now also be a :term:`path-like object`, not only a string.
234
Georg Brandl116aa622007-08-15 14:28:22 +0000235
236.. function:: register_converter(typename, callable)
237
238 Registers a callable to convert a bytestring from the database into a custom
239 Python type. The callable will be invoked for all database values that are of
240 the type *typename*. Confer the parameter *detect_types* of the :func:`connect`
Sergey Fedoseev831c2972018-07-03 16:59:32 +0500241 function for how the type detection works. Note that *typename* and the name of
242 the type in your query are matched in case-insensitive manner.
Georg Brandl116aa622007-08-15 14:28:22 +0000243
244
245.. function:: register_adapter(type, callable)
246
247 Registers a callable to convert the custom Python type *type* into one of
248 SQLite's supported types. The callable *callable* accepts as single parameter
Georg Brandl5c106642007-11-29 17:41:05 +0000249 the Python value, and must return a value of the following types: int,
Antoine Pitrouf06917e2010-02-02 23:00:29 +0000250 float, str or bytes.
Georg Brandl116aa622007-08-15 14:28:22 +0000251
252
253.. function:: complete_statement(sql)
254
255 Returns :const:`True` if the string *sql* contains one or more complete SQL
256 statements terminated by semicolons. It does not verify that the SQL is
257 syntactically correct, only that there are no unclosed string literals and the
258 statement is terminated by a semicolon.
259
260 This can be used to build a shell for SQLite, as in the following example:
261
262
263 .. literalinclude:: ../includes/sqlite3/complete_statement.py
264
265
266.. function:: enable_callback_tracebacks(flag)
267
268 By default you will not get any tracebacks in user-defined functions,
Serhiy Storchakafbc1c262013-11-29 12:17:13 +0200269 aggregates, converters, authorizer callbacks etc. If you want to debug them,
270 you can call this function with *flag* set to ``True``. Afterwards, you will
271 get tracebacks from callbacks on ``sys.stderr``. Use :const:`False` to
272 disable the feature again.
Georg Brandl116aa622007-08-15 14:28:22 +0000273
274
275.. _sqlite3-connection-objects:
276
277Connection Objects
278------------------
279
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000280.. class:: Connection
281
282 A SQLite database connection has the following attributes and methods:
Georg Brandl116aa622007-08-15 14:28:22 +0000283
R David Murray6db23352012-09-30 20:44:43 -0400284 .. attribute:: isolation_level
Georg Brandl116aa622007-08-15 14:28:22 +0000285
Berker Peksaga71fed02018-07-29 12:01:38 +0300286 Get or set the current default isolation level. :const:`None` for autocommit mode or
R David Murray6db23352012-09-30 20:44:43 -0400287 one of "DEFERRED", "IMMEDIATE" or "EXCLUSIVE". See section
288 :ref:`sqlite3-controlling-transactions` for a more detailed explanation.
Georg Brandl116aa622007-08-15 14:28:22 +0000289
R David Murray6db23352012-09-30 20:44:43 -0400290 .. attribute:: in_transaction
R. David Murrayd35251d2010-06-01 01:32:12 +0000291
R David Murray6db23352012-09-30 20:44:43 -0400292 :const:`True` if a transaction is active (there are uncommitted changes),
293 :const:`False` otherwise. Read-only attribute.
R. David Murrayd35251d2010-06-01 01:32:12 +0000294
R David Murray6db23352012-09-30 20:44:43 -0400295 .. versionadded:: 3.2
Georg Brandl116aa622007-08-15 14:28:22 +0000296
Serhiy Storchakaef113cd2016-08-29 14:29:55 +0300297 .. method:: cursor(factory=Cursor)
Georg Brandl116aa622007-08-15 14:28:22 +0000298
Serhiy Storchakaef113cd2016-08-29 14:29:55 +0300299 The cursor method accepts a single optional parameter *factory*. If
300 supplied, this must be a callable returning an instance of :class:`Cursor`
301 or its subclasses.
Georg Brandl116aa622007-08-15 14:28:22 +0000302
R David Murray6db23352012-09-30 20:44:43 -0400303 .. method:: commit()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000304
R David Murray6db23352012-09-30 20:44:43 -0400305 This method commits the current transaction. If you don't call this method,
306 anything you did since the last call to ``commit()`` is not visible from
307 other database connections. If you wonder why you don't see the data you've
308 written to the database, please check you didn't forget to call this method.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000309
R David Murray6db23352012-09-30 20:44:43 -0400310 .. method:: rollback()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000311
R David Murray6db23352012-09-30 20:44:43 -0400312 This method rolls back any changes to the database since the last call to
313 :meth:`commit`.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000314
R David Murray6db23352012-09-30 20:44:43 -0400315 .. method:: close()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000316
R David Murray6db23352012-09-30 20:44:43 -0400317 This closes the database connection. Note that this does not automatically
318 call :meth:`commit`. If you just close your database connection without
319 calling :meth:`commit` first, your changes will be lost!
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000320
Berker Peksagc4154402016-06-12 13:41:47 +0300321 .. method:: execute(sql[, parameters])
Georg Brandl116aa622007-08-15 14:28:22 +0000322
Berker Peksagc4154402016-06-12 13:41:47 +0300323 This is a nonstandard shortcut that creates a cursor object by calling
324 the :meth:`~Connection.cursor` method, calls the cursor's
325 :meth:`~Cursor.execute` method with the *parameters* given, and returns
326 the cursor.
Georg Brandl116aa622007-08-15 14:28:22 +0000327
Berker Peksagc4154402016-06-12 13:41:47 +0300328 .. method:: executemany(sql[, parameters])
Georg Brandl116aa622007-08-15 14:28:22 +0000329
Berker Peksagc4154402016-06-12 13:41:47 +0300330 This is a nonstandard shortcut that creates a cursor object by
331 calling the :meth:`~Connection.cursor` method, calls the cursor's
332 :meth:`~Cursor.executemany` method with the *parameters* given, and
333 returns the cursor.
Georg Brandl116aa622007-08-15 14:28:22 +0000334
R David Murray6db23352012-09-30 20:44:43 -0400335 .. method:: executescript(sql_script)
Georg Brandl116aa622007-08-15 14:28:22 +0000336
Berker Peksagc4154402016-06-12 13:41:47 +0300337 This is a nonstandard shortcut that creates a cursor object by
338 calling the :meth:`~Connection.cursor` method, calls the cursor's
339 :meth:`~Cursor.executescript` method with the given *sql_script*, and
340 returns the cursor.
Georg Brandl116aa622007-08-15 14:28:22 +0000341
Sergey Fedoseev08308582018-07-08 12:09:20 +0500342 .. method:: create_function(name, num_params, func, *, deterministic=False)
Georg Brandl116aa622007-08-15 14:28:22 +0000343
R David Murray6db23352012-09-30 20:44:43 -0400344 Creates a user-defined function that you can later use from within SQL
345 statements under the function name *name*. *num_params* is the number of
Berker Peksagfa0f62d2016-03-27 22:39:14 +0300346 parameters the function accepts (if *num_params* is -1, the function may
347 take any number of arguments), and *func* is a Python callable that is
Sergey Fedoseev08308582018-07-08 12:09:20 +0500348 called as the SQL function. If *deterministic* is true, the created function
349 is marked as `deterministic <https://sqlite.org/deterministic.html>`_, which
350 allows SQLite to perform additional optimizations. This flag is supported by
Marcin Niemirabc9aa812018-07-08 14:02:58 +0200351 SQLite 3.8.3 or higher, :exc:`NotSupportedError` will be raised if used
Sergey Fedoseev08308582018-07-08 12:09:20 +0500352 with older versions.
Georg Brandl116aa622007-08-15 14:28:22 +0000353
R David Murray6db23352012-09-30 20:44:43 -0400354 The function can return any of the types supported by SQLite: bytes, str, int,
Serhiy Storchakaecf41da2016-10-19 16:29:26 +0300355 float and ``None``.
Georg Brandl116aa622007-08-15 14:28:22 +0000356
Sergey Fedoseev08308582018-07-08 12:09:20 +0500357 .. versionchanged:: 3.8
358 The *deterministic* parameter was added.
359
R David Murray6db23352012-09-30 20:44:43 -0400360 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000361
R David Murray6db23352012-09-30 20:44:43 -0400362 .. literalinclude:: ../includes/sqlite3/md5func.py
Georg Brandl116aa622007-08-15 14:28:22 +0000363
364
R David Murray6db23352012-09-30 20:44:43 -0400365 .. method:: create_aggregate(name, num_params, aggregate_class)
Georg Brandl116aa622007-08-15 14:28:22 +0000366
R David Murray6db23352012-09-30 20:44:43 -0400367 Creates a user-defined aggregate function.
Georg Brandl116aa622007-08-15 14:28:22 +0000368
R David Murray6db23352012-09-30 20:44:43 -0400369 The aggregate class must implement a ``step`` method, which accepts the number
Berker Peksagfa0f62d2016-03-27 22:39:14 +0300370 of parameters *num_params* (if *num_params* is -1, the function may take
371 any number of arguments), and a ``finalize`` method which will return the
R David Murray6db23352012-09-30 20:44:43 -0400372 final result of the aggregate.
Georg Brandl116aa622007-08-15 14:28:22 +0000373
R David Murray6db23352012-09-30 20:44:43 -0400374 The ``finalize`` method can return any of the types supported by SQLite:
Serhiy Storchakaecf41da2016-10-19 16:29:26 +0300375 bytes, str, int, float and ``None``.
Georg Brandl116aa622007-08-15 14:28:22 +0000376
R David Murray6db23352012-09-30 20:44:43 -0400377 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000378
R David Murray6db23352012-09-30 20:44:43 -0400379 .. literalinclude:: ../includes/sqlite3/mysumaggr.py
Georg Brandl116aa622007-08-15 14:28:22 +0000380
381
R David Murray6db23352012-09-30 20:44:43 -0400382 .. method:: create_collation(name, callable)
Georg Brandl116aa622007-08-15 14:28:22 +0000383
R David Murray6db23352012-09-30 20:44:43 -0400384 Creates a collation with the specified *name* and *callable*. The callable will
385 be passed two string arguments. It should return -1 if the first is ordered
386 lower than the second, 0 if they are ordered equal and 1 if the first is ordered
387 higher than the second. Note that this controls sorting (ORDER BY in SQL) so
388 your comparisons don't affect other SQL operations.
Georg Brandl116aa622007-08-15 14:28:22 +0000389
R David Murray6db23352012-09-30 20:44:43 -0400390 Note that the callable will get its parameters as Python bytestrings, which will
391 normally be encoded in UTF-8.
Georg Brandl116aa622007-08-15 14:28:22 +0000392
R David Murray6db23352012-09-30 20:44:43 -0400393 The following example shows a custom collation that sorts "the wrong way":
Georg Brandl116aa622007-08-15 14:28:22 +0000394
R David Murray6db23352012-09-30 20:44:43 -0400395 .. literalinclude:: ../includes/sqlite3/collation_reverse.py
Georg Brandl116aa622007-08-15 14:28:22 +0000396
Serhiy Storchakaecf41da2016-10-19 16:29:26 +0300397 To remove a collation, call ``create_collation`` with ``None`` as callable::
Georg Brandl116aa622007-08-15 14:28:22 +0000398
R David Murray6db23352012-09-30 20:44:43 -0400399 con.create_collation("reverse", None)
Georg Brandl116aa622007-08-15 14:28:22 +0000400
401
R David Murray6db23352012-09-30 20:44:43 -0400402 .. method:: interrupt()
Georg Brandl116aa622007-08-15 14:28:22 +0000403
R David Murray6db23352012-09-30 20:44:43 -0400404 You can call this method from a different thread to abort any queries that might
405 be executing on the connection. The query will then abort and the caller will
406 get an exception.
Georg Brandl116aa622007-08-15 14:28:22 +0000407
408
R David Murray6db23352012-09-30 20:44:43 -0400409 .. method:: set_authorizer(authorizer_callback)
Georg Brandl116aa622007-08-15 14:28:22 +0000410
R David Murray6db23352012-09-30 20:44:43 -0400411 This routine registers a callback. The callback is invoked for each attempt to
412 access a column of a table in the database. The callback should return
413 :const:`SQLITE_OK` if access is allowed, :const:`SQLITE_DENY` if the entire SQL
414 statement should be aborted with an error and :const:`SQLITE_IGNORE` if the
415 column should be treated as a NULL value. These constants are available in the
416 :mod:`sqlite3` module.
Georg Brandl116aa622007-08-15 14:28:22 +0000417
R David Murray6db23352012-09-30 20:44:43 -0400418 The first argument to the callback signifies what kind of operation is to be
419 authorized. The second and third argument will be arguments or :const:`None`
420 depending on the first argument. The 4th argument is the name of the database
421 ("main", "temp", etc.) if applicable. The 5th argument is the name of the
422 inner-most trigger or view that is responsible for the access attempt or
423 :const:`None` if this access attempt is directly from input SQL code.
Georg Brandl116aa622007-08-15 14:28:22 +0000424
R David Murray6db23352012-09-30 20:44:43 -0400425 Please consult the SQLite documentation about the possible values for the first
426 argument and the meaning of the second and third argument depending on the first
427 one. All necessary constants are available in the :mod:`sqlite3` module.
Georg Brandl116aa622007-08-15 14:28:22 +0000428
Georg Brandl116aa622007-08-15 14:28:22 +0000429
R David Murray6db23352012-09-30 20:44:43 -0400430 .. method:: set_progress_handler(handler, n)
Georg Brandl116aa622007-08-15 14:28:22 +0000431
R David Murray6db23352012-09-30 20:44:43 -0400432 This routine registers a callback. The callback is invoked for every *n*
433 instructions of the SQLite virtual machine. This is useful if you want to
434 get called from SQLite during long-running operations, for example to update
435 a GUI.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000436
R David Murray6db23352012-09-30 20:44:43 -0400437 If you want to clear any previously installed progress handler, call the
438 method with :const:`None` for *handler*.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000439
Simon Willisonac03c032017-11-02 07:34:12 -0700440 Returning a non-zero value from the handler function will terminate the
441 currently executing query and cause it to raise an :exc:`OperationalError`
442 exception.
443
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000444
R David Murray842ca5f2012-09-30 20:49:19 -0400445 .. method:: set_trace_callback(trace_callback)
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000446
R David Murray842ca5f2012-09-30 20:49:19 -0400447 Registers *trace_callback* to be called for each SQL statement that is
448 actually executed by the SQLite backend.
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200449
R David Murray842ca5f2012-09-30 20:49:19 -0400450 The only argument passed to the callback is the statement (as string) that
451 is being executed. The return value of the callback is ignored. Note that
452 the backend does not only run statements passed to the :meth:`Cursor.execute`
453 methods. Other sources include the transaction management of the Python
454 module and the execution of triggers defined in the current database.
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200455
R David Murray842ca5f2012-09-30 20:49:19 -0400456 Passing :const:`None` as *trace_callback* will disable the trace callback.
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200457
R David Murray842ca5f2012-09-30 20:49:19 -0400458 .. versionadded:: 3.3
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200459
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200460
R David Murray6db23352012-09-30 20:44:43 -0400461 .. method:: enable_load_extension(enabled)
Antoine Pitrou5bfa0622011-04-04 00:12:04 +0200462
R David Murray6db23352012-09-30 20:44:43 -0400463 This routine allows/disallows the SQLite engine to load SQLite extensions
464 from shared libraries. SQLite extensions can define new functions,
465 aggregates or whole new virtual table implementations. One well-known
466 extension is the fulltext-search extension distributed with SQLite.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000467
R David Murray6db23352012-09-30 20:44:43 -0400468 Loadable extensions are disabled by default. See [#f1]_.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000469
R David Murray6db23352012-09-30 20:44:43 -0400470 .. versionadded:: 3.2
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +0200471
R David Murray6db23352012-09-30 20:44:43 -0400472 .. literalinclude:: ../includes/sqlite3/load_extension.py
Georg Brandl67b21b72010-08-17 15:07:14 +0000473
R David Murray6db23352012-09-30 20:44:43 -0400474 .. method:: load_extension(path)
Gerhard Häringf9cee222010-03-05 15:20:03 +0000475
R David Murray6db23352012-09-30 20:44:43 -0400476 This routine loads a SQLite extension from a shared library. You have to
477 enable extension loading with :meth:`enable_load_extension` before you can
478 use this routine.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000479
R David Murray6db23352012-09-30 20:44:43 -0400480 Loadable extensions are disabled by default. See [#f1]_.
Gerhard Häringf9cee222010-03-05 15:20:03 +0000481
R David Murray6db23352012-09-30 20:44:43 -0400482 .. versionadded:: 3.2
Gerhard Häringe0941c52010-10-03 21:47:06 +0000483
R David Murray6db23352012-09-30 20:44:43 -0400484 .. attribute:: row_factory
Petri Lehtinen4d2bfb52012-03-01 21:18:34 +0200485
R David Murray6db23352012-09-30 20:44:43 -0400486 You can change this attribute to a callable that accepts the cursor and the
487 original row as a tuple and will return the real result row. This way, you can
488 implement more advanced ways of returning results, such as returning an object
489 that can also access columns by name.
Georg Brandl116aa622007-08-15 14:28:22 +0000490
R David Murray6db23352012-09-30 20:44:43 -0400491 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000492
R David Murray6db23352012-09-30 20:44:43 -0400493 .. literalinclude:: ../includes/sqlite3/row_factory.py
Georg Brandl116aa622007-08-15 14:28:22 +0000494
R David Murray6db23352012-09-30 20:44:43 -0400495 If returning a tuple doesn't suffice and you want name-based access to
496 columns, you should consider setting :attr:`row_factory` to the
497 highly-optimized :class:`sqlite3.Row` type. :class:`Row` provides both
498 index-based and case-insensitive name-based access to columns with almost no
499 memory overhead. It will probably be better than your own custom
500 dictionary-based approach or even a db_row based solution.
Georg Brandl116aa622007-08-15 14:28:22 +0000501
R David Murray6db23352012-09-30 20:44:43 -0400502 .. XXX what's a db_row-based solution?
Georg Brandl116aa622007-08-15 14:28:22 +0000503
Georg Brandl116aa622007-08-15 14:28:22 +0000504
R David Murray6db23352012-09-30 20:44:43 -0400505 .. attribute:: text_factory
Georg Brandl116aa622007-08-15 14:28:22 +0000506
R David Murray6db23352012-09-30 20:44:43 -0400507 Using this attribute you can control what objects are returned for the ``TEXT``
508 data type. By default, this attribute is set to :class:`str` and the
509 :mod:`sqlite3` module will return Unicode objects for ``TEXT``. If you want to
510 return bytestrings instead, you can set it to :class:`bytes`.
Georg Brandl116aa622007-08-15 14:28:22 +0000511
R David Murray6db23352012-09-30 20:44:43 -0400512 You can also set it to any other callable that accepts a single bytestring
513 parameter and returns the resulting object.
Georg Brandl116aa622007-08-15 14:28:22 +0000514
R David Murray6db23352012-09-30 20:44:43 -0400515 See the following example code for illustration:
Georg Brandl116aa622007-08-15 14:28:22 +0000516
R David Murray6db23352012-09-30 20:44:43 -0400517 .. literalinclude:: ../includes/sqlite3/text_factory.py
Georg Brandl116aa622007-08-15 14:28:22 +0000518
519
R David Murray6db23352012-09-30 20:44:43 -0400520 .. attribute:: total_changes
Georg Brandl116aa622007-08-15 14:28:22 +0000521
R David Murray6db23352012-09-30 20:44:43 -0400522 Returns the total number of database rows that have been modified, inserted, or
523 deleted since the database connection was opened.
Georg Brandl116aa622007-08-15 14:28:22 +0000524
525
Berker Peksag557a0632016-03-27 18:46:18 +0300526 .. method:: iterdump
Christian Heimesbbe741d2008-03-28 10:53:29 +0000527
R David Murray6db23352012-09-30 20:44:43 -0400528 Returns an iterator to dump the database in an SQL text format. Useful when
529 saving an in-memory database for later restoration. This function provides
530 the same capabilities as the :kbd:`.dump` command in the :program:`sqlite3`
531 shell.
Christian Heimesbbe741d2008-03-28 10:53:29 +0000532
R David Murray6db23352012-09-30 20:44:43 -0400533 Example::
Christian Heimesbbe741d2008-03-28 10:53:29 +0000534
R David Murray6db23352012-09-30 20:44:43 -0400535 # Convert file existing_db.db to SQL dump file dump.sql
Berker Peksag557a0632016-03-27 18:46:18 +0300536 import sqlite3
Christian Heimesbbe741d2008-03-28 10:53:29 +0000537
R David Murray6db23352012-09-30 20:44:43 -0400538 con = sqlite3.connect('existing_db.db')
539 with open('dump.sql', 'w') as f:
540 for line in con.iterdump():
541 f.write('%s\n' % line)
Xtreak287b84d2019-05-20 03:22:20 +0530542 con.close()
Christian Heimesbbe741d2008-03-28 10:53:29 +0000543
544
Emanuele Gaifasd7aed412018-03-10 23:08:31 +0100545 .. method:: backup(target, *, pages=0, progress=None, name="main", sleep=0.250)
546
547 This method makes a backup of a SQLite database even while it's being accessed
548 by other clients, or concurrently by the same connection. The copy will be
549 written into the mandatory argument *target*, that must be another
550 :class:`Connection` instance.
551
552 By default, or when *pages* is either ``0`` or a negative integer, the entire
553 database is copied in a single step; otherwise the method performs a loop
554 copying up to *pages* pages at a time.
555
556 If *progress* is specified, it must either be ``None`` or a callable object that
557 will be executed at each iteration with three integer arguments, respectively
558 the *status* of the last iteration, the *remaining* number of pages still to be
559 copied and the *total* number of pages.
560
561 The *name* argument specifies the database name that will be copied: it must be
562 a string containing either ``"main"``, the default, to indicate the main
563 database, ``"temp"`` to indicate the temporary database or the name specified
564 after the ``AS`` keyword in an ``ATTACH DATABASE`` statement for an attached
565 database.
566
567 The *sleep* argument specifies the number of seconds to sleep by between
568 successive attempts to backup remaining pages, can be specified either as an
569 integer or a floating point value.
570
571 Example 1, copy an existing database into another::
572
573 import sqlite3
574
575 def progress(status, remaining, total):
576 print(f'Copied {total-remaining} of {total} pages...')
577
578 con = sqlite3.connect('existing_db.db')
Xtreak287b84d2019-05-20 03:22:20 +0530579 bck = sqlite3.connect('backup.db')
580 with bck:
Emanuele Gaifasd7aed412018-03-10 23:08:31 +0100581 con.backup(bck, pages=1, progress=progress)
Xtreak287b84d2019-05-20 03:22:20 +0530582 bck.close()
583 con.close()
Emanuele Gaifasd7aed412018-03-10 23:08:31 +0100584
585 Example 2, copy an existing database into a transient copy::
586
587 import sqlite3
588
589 source = sqlite3.connect('existing_db.db')
590 dest = sqlite3.connect(':memory:')
591 source.backup(dest)
592
593 Availability: SQLite 3.6.11 or higher
594
595 .. versionadded:: 3.7
596
597
Georg Brandl116aa622007-08-15 14:28:22 +0000598.. _sqlite3-cursor-objects:
599
600Cursor Objects
601--------------
602
Georg Brandl96115fb22010-10-17 09:33:24 +0000603.. class:: Cursor
Georg Brandl116aa622007-08-15 14:28:22 +0000604
Georg Brandl96115fb22010-10-17 09:33:24 +0000605 A :class:`Cursor` instance has the following attributes and methods.
Georg Brandl116aa622007-08-15 14:28:22 +0000606
Serhiy Storchaka913876d2018-10-28 13:41:26 +0200607 .. index:: single: ? (question mark); in SQL statements
608 .. index:: single: : (colon); in SQL statements
609
Berker Peksagc4154402016-06-12 13:41:47 +0300610 .. method:: execute(sql[, parameters])
Georg Brandl116aa622007-08-15 14:28:22 +0000611
Zachary Ware9d085622014-04-01 12:21:56 -0500612 Executes an SQL statement. The SQL statement may be parameterized (i. e.
R David Murray6db23352012-09-30 20:44:43 -0400613 placeholders instead of SQL literals). The :mod:`sqlite3` module supports two
614 kinds of placeholders: question marks (qmark style) and named placeholders
615 (named style).
Georg Brandl116aa622007-08-15 14:28:22 +0000616
R David Murray6db23352012-09-30 20:44:43 -0400617 Here's an example of both styles:
Georg Brandl116aa622007-08-15 14:28:22 +0000618
R David Murray6db23352012-09-30 20:44:43 -0400619 .. literalinclude:: ../includes/sqlite3/execute_1.py
Georg Brandl116aa622007-08-15 14:28:22 +0000620
R David Murray6db23352012-09-30 20:44:43 -0400621 :meth:`execute` will only execute a single SQL statement. If you try to execute
Berker Peksag7d92f892016-08-25 00:50:24 +0300622 more than one statement with it, it will raise a :exc:`.Warning`. Use
R David Murray6db23352012-09-30 20:44:43 -0400623 :meth:`executescript` if you want to execute multiple SQL statements with one
624 call.
Georg Brandl116aa622007-08-15 14:28:22 +0000625
626
R David Murray6db23352012-09-30 20:44:43 -0400627 .. method:: executemany(sql, seq_of_parameters)
Georg Brandl116aa622007-08-15 14:28:22 +0000628
R David Murray6db23352012-09-30 20:44:43 -0400629 Executes an SQL command against all parameter sequences or mappings found in
Berker Peksagc4154402016-06-12 13:41:47 +0300630 the sequence *seq_of_parameters*. The :mod:`sqlite3` module also allows
631 using an :term:`iterator` yielding parameters instead of a sequence.
Georg Brandl116aa622007-08-15 14:28:22 +0000632
R David Murray6db23352012-09-30 20:44:43 -0400633 .. literalinclude:: ../includes/sqlite3/executemany_1.py
Georg Brandl116aa622007-08-15 14:28:22 +0000634
R David Murray6db23352012-09-30 20:44:43 -0400635 Here's a shorter example using a :term:`generator`:
Georg Brandl116aa622007-08-15 14:28:22 +0000636
R David Murray6db23352012-09-30 20:44:43 -0400637 .. literalinclude:: ../includes/sqlite3/executemany_2.py
Georg Brandl116aa622007-08-15 14:28:22 +0000638
639
R David Murray6db23352012-09-30 20:44:43 -0400640 .. method:: executescript(sql_script)
Georg Brandl116aa622007-08-15 14:28:22 +0000641
R David Murray6db23352012-09-30 20:44:43 -0400642 This is a nonstandard convenience method for executing multiple SQL statements
643 at once. It issues a ``COMMIT`` statement first, then executes the SQL script it
644 gets as a parameter.
Georg Brandl116aa622007-08-15 14:28:22 +0000645
Berker Peksagc4154402016-06-12 13:41:47 +0300646 *sql_script* can be an instance of :class:`str`.
Georg Brandl116aa622007-08-15 14:28:22 +0000647
R David Murray6db23352012-09-30 20:44:43 -0400648 Example:
Georg Brandl116aa622007-08-15 14:28:22 +0000649
R David Murray6db23352012-09-30 20:44:43 -0400650 .. literalinclude:: ../includes/sqlite3/executescript.py
Georg Brandl116aa622007-08-15 14:28:22 +0000651
652
R David Murray6db23352012-09-30 20:44:43 -0400653 .. method:: fetchone()
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000654
R David Murray6db23352012-09-30 20:44:43 -0400655 Fetches the next row of a query result set, returning a single sequence,
656 or :const:`None` when no more data is available.
Christian Heimesfdab48e2008-01-20 09:06:41 +0000657
658
R David Murray6db23352012-09-30 20:44:43 -0400659 .. method:: fetchmany(size=cursor.arraysize)
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000660
R David Murray6db23352012-09-30 20:44:43 -0400661 Fetches the next set of rows of a query result, returning a list. An empty
662 list is returned when no more rows are available.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000663
R David Murray6db23352012-09-30 20:44:43 -0400664 The number of rows to fetch per call is specified by the *size* parameter.
665 If it is not given, the cursor's arraysize determines the number of rows
666 to be fetched. The method should try to fetch as many rows as indicated by
667 the size parameter. If this is not possible due to the specified number of
668 rows not being available, fewer rows may be returned.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000669
R David Murray6db23352012-09-30 20:44:43 -0400670 Note there are performance considerations involved with the *size* parameter.
671 For optimal performance, it is usually best to use the arraysize attribute.
672 If the *size* parameter is used, then it is best for it to retain the same
673 value from one :meth:`fetchmany` call to the next.
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +0000674
R David Murray6db23352012-09-30 20:44:43 -0400675 .. method:: fetchall()
Christian Heimesfdab48e2008-01-20 09:06:41 +0000676
R David Murray6db23352012-09-30 20:44:43 -0400677 Fetches all (remaining) rows of a query result, returning a list. Note that
678 the cursor's arraysize attribute can affect the performance of this operation.
679 An empty list is returned when no rows are available.
Christian Heimesfdab48e2008-01-20 09:06:41 +0000680
Berker Peksagf70fe6f2016-03-27 21:51:02 +0300681 .. method:: close()
682
683 Close the cursor now (rather than whenever ``__del__`` is called).
684
Berker Peksaged789f92016-08-25 00:45:07 +0300685 The cursor will be unusable from this point forward; a :exc:`ProgrammingError`
Berker Peksagf70fe6f2016-03-27 21:51:02 +0300686 exception will be raised if any operation is attempted with the cursor.
Christian Heimesfdab48e2008-01-20 09:06:41 +0000687
R David Murray6db23352012-09-30 20:44:43 -0400688 .. attribute:: rowcount
Georg Brandl116aa622007-08-15 14:28:22 +0000689
R David Murray6db23352012-09-30 20:44:43 -0400690 Although the :class:`Cursor` class of the :mod:`sqlite3` module implements this
691 attribute, the database engine's own support for the determination of "rows
692 affected"/"rows selected" is quirky.
Georg Brandl116aa622007-08-15 14:28:22 +0000693
R David Murray6db23352012-09-30 20:44:43 -0400694 For :meth:`executemany` statements, the number of modifications are summed up
695 into :attr:`rowcount`.
Georg Brandl116aa622007-08-15 14:28:22 +0000696
R David Murray6db23352012-09-30 20:44:43 -0400697 As required by the Python DB API Spec, the :attr:`rowcount` attribute "is -1 in
698 case no ``executeXX()`` has been performed on the cursor or the rowcount of the
699 last operation is not determinable by the interface". This includes ``SELECT``
700 statements because we cannot determine the number of rows a query produced
701 until all rows were fetched.
Georg Brandl116aa622007-08-15 14:28:22 +0000702
R David Murray6db23352012-09-30 20:44:43 -0400703 With SQLite versions before 3.6.5, :attr:`rowcount` is set to 0 if
704 you make a ``DELETE FROM table`` without any condition.
Guido van Rossum04110fb2007-08-24 16:32:05 +0000705
R David Murray6db23352012-09-30 20:44:43 -0400706 .. attribute:: lastrowid
Gerhard Häringd3372792008-03-29 19:13:55 +0000707
R David Murray6db23352012-09-30 20:44:43 -0400708 This read-only attribute provides the rowid of the last modified row. It is
Berker Peksage0b70cd2016-06-14 15:25:36 +0300709 only set if you issued an ``INSERT`` or a ``REPLACE`` statement using the
710 :meth:`execute` method. For operations other than ``INSERT`` or
711 ``REPLACE`` or when :meth:`executemany` is called, :attr:`lastrowid` is
712 set to :const:`None`.
713
714 If the ``INSERT`` or ``REPLACE`` statement failed to insert the previous
715 successful rowid is returned.
716
717 .. versionchanged:: 3.6
718 Added support for the ``REPLACE`` statement.
Georg Brandl116aa622007-08-15 14:28:22 +0000719
csabella02e12132017-04-04 01:16:14 -0400720 .. attribute:: arraysize
721
722 Read/write attribute that controls the number of rows returned by :meth:`fetchmany`.
723 The default value is 1 which means a single row would be fetched per call.
724
R David Murray6db23352012-09-30 20:44:43 -0400725 .. attribute:: description
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000726
R David Murray6db23352012-09-30 20:44:43 -0400727 This read-only attribute provides the column names of the last query. To
728 remain compatible with the Python DB API, it returns a 7-tuple for each
729 column where the last six items of each tuple are :const:`None`.
Georg Brandl48310cd2009-01-03 21:18:54 +0000730
R David Murray6db23352012-09-30 20:44:43 -0400731 It is set for ``SELECT`` statements without any matching rows as well.
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000732
Ezio Melotti62564db2016-03-18 20:10:36 +0200733 .. attribute:: connection
734
735 This read-only attribute provides the SQLite database :class:`Connection`
736 used by the :class:`Cursor` object. A :class:`Cursor` object created by
737 calling :meth:`con.cursor() <Connection.cursor>` will have a
738 :attr:`connection` attribute that refers to *con*::
739
740 >>> con = sqlite3.connect(":memory:")
741 >>> cur = con.cursor()
742 >>> cur.connection == con
743 True
744
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000745.. _sqlite3-row-objects:
746
747Row Objects
748-----------
749
750.. class:: Row
751
752 A :class:`Row` instance serves as a highly optimized
Georg Brandl48310cd2009-01-03 21:18:54 +0000753 :attr:`~Connection.row_factory` for :class:`Connection` objects.
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000754 It tries to mimic a tuple in most of its features.
755
756 It supports mapping access by column name and index, iteration,
757 representation, equality testing and :func:`len`.
758
759 If two :class:`Row` objects have exactly the same columns and their
760 members are equal, they compare equal.
Georg Brandl48310cd2009-01-03 21:18:54 +0000761
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000762 .. method:: keys
763
R David Murray092135e2014-06-05 15:16:38 -0400764 This method returns a list of column names. Immediately after a query,
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000765 it is the first member of each tuple in :attr:`Cursor.description`.
766
Serhiy Storchaka72e731c2015-03-31 13:33:11 +0300767 .. versionchanged:: 3.5
768 Added support of slicing.
769
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000770Let's assume we initialize a table as in the example given above::
771
Senthil Kumaran946eb862011-07-03 10:17:22 -0700772 conn = sqlite3.connect(":memory:")
773 c = conn.cursor()
774 c.execute('''create table stocks
775 (date text, trans text, symbol text,
776 qty real, price real)''')
777 c.execute("""insert into stocks
778 values ('2006-01-05','BUY','RHAT',100,35.14)""")
779 conn.commit()
780 c.close()
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000781
782Now we plug :class:`Row` in::
783
Senthil Kumaran946eb862011-07-03 10:17:22 -0700784 >>> conn.row_factory = sqlite3.Row
785 >>> c = conn.cursor()
786 >>> c.execute('select * from stocks')
787 <sqlite3.Cursor object at 0x7f4e7dd8fa80>
788 >>> r = c.fetchone()
789 >>> type(r)
790 <class 'sqlite3.Row'>
791 >>> tuple(r)
792 ('2006-01-05', 'BUY', 'RHAT', 100.0, 35.14)
793 >>> len(r)
794 5
795 >>> r[2]
796 'RHAT'
797 >>> r.keys()
798 ['date', 'trans', 'symbol', 'qty', 'price']
799 >>> r['qty']
800 100.0
801 >>> for member in r:
802 ... print(member)
803 ...
804 2006-01-05
805 BUY
806 RHAT
807 100.0
808 35.14
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000809
810
Berker Peksaged789f92016-08-25 00:45:07 +0300811.. _sqlite3-exceptions:
812
813Exceptions
814----------
815
816.. exception:: Warning
817
818 A subclass of :exc:`Exception`.
819
820.. exception:: Error
821
822 The base class of the other exceptions in this module. It is a subclass
823 of :exc:`Exception`.
824
825.. exception:: DatabaseError
826
827 Exception raised for errors that are related to the database.
828
829.. exception:: IntegrityError
830
831 Exception raised when the relational integrity of the database is affected,
832 e.g. a foreign key check fails. It is a subclass of :exc:`DatabaseError`.
833
834.. exception:: ProgrammingError
835
836 Exception raised for programming errors, e.g. table not found or already
837 exists, syntax error in the SQL statement, wrong number of parameters
838 specified, etc. It is a subclass of :exc:`DatabaseError`.
839
Zackery Spytz71ede002018-06-13 03:09:31 -0600840.. exception:: OperationalError
841
842 Exception raised for errors that are related to the database's operation
843 and not necessarily under the control of the programmer, e.g. an unexpected
844 disconnect occurs, the data source name is not found, a transaction could
845 not be processed, etc. It is a subclass of :exc:`DatabaseError`.
846
Marcin Niemirabc9aa812018-07-08 14:02:58 +0200847.. exception:: NotSupportedError
848
849 Exception raised in case a method or database API was used which is not
850 supported by the database, e.g. calling the :meth:`~Connection.rollback`
851 method on a connection that does not support transaction or has
852 transactions turned off. It is a subclass of :exc:`DatabaseError`.
853
Berker Peksaged789f92016-08-25 00:45:07 +0300854
Georg Brandl116aa622007-08-15 14:28:22 +0000855.. _sqlite3-types:
856
857SQLite and Python types
858-----------------------
859
860
861Introduction
862^^^^^^^^^^^^
863
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000864SQLite natively supports the following types: ``NULL``, ``INTEGER``,
865``REAL``, ``TEXT``, ``BLOB``.
Georg Brandl116aa622007-08-15 14:28:22 +0000866
867The following Python types can thus be sent to SQLite without any problem:
868
Georg Brandlf6945182008-02-01 11:56:49 +0000869+-------------------------------+-------------+
870| Python type | SQLite type |
871+===============================+=============+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000872| :const:`None` | ``NULL`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000873+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000874| :class:`int` | ``INTEGER`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000875+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000876| :class:`float` | ``REAL`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000877+-------------------------------+-------------+
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000878| :class:`str` | ``TEXT`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000879+-------------------------------+-------------+
Antoine Pitrouf06917e2010-02-02 23:00:29 +0000880| :class:`bytes` | ``BLOB`` |
Georg Brandlf6945182008-02-01 11:56:49 +0000881+-------------------------------+-------------+
Georg Brandl116aa622007-08-15 14:28:22 +0000882
Benjamin Petersonf10a79a2008-10-11 00:49:57 +0000883
Georg Brandl116aa622007-08-15 14:28:22 +0000884This is how SQLite types are converted to Python types by default:
885
Zachary Ware9d085622014-04-01 12:21:56 -0500886+-------------+----------------------------------------------+
887| SQLite type | Python type |
888+=============+==============================================+
889| ``NULL`` | :const:`None` |
890+-------------+----------------------------------------------+
891| ``INTEGER`` | :class:`int` |
892+-------------+----------------------------------------------+
893| ``REAL`` | :class:`float` |
894+-------------+----------------------------------------------+
895| ``TEXT`` | depends on :attr:`~Connection.text_factory`, |
896| | :class:`str` by default |
897+-------------+----------------------------------------------+
898| ``BLOB`` | :class:`bytes` |
899+-------------+----------------------------------------------+
Georg Brandl116aa622007-08-15 14:28:22 +0000900
901The type system of the :mod:`sqlite3` module is extensible in two ways: you can
902store additional Python types in a SQLite database via object adaptation, and
903you can let the :mod:`sqlite3` module convert SQLite types to different Python
904types via converters.
905
906
907Using adapters to store additional Python types in SQLite databases
908^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
909
910As described before, SQLite supports only a limited set of types natively. To
911use other Python types with SQLite, you must **adapt** them to one of the
Georg Brandl5c106642007-11-29 17:41:05 +0000912sqlite3 module's supported types for SQLite: one of NoneType, int, float,
Antoine Pitrouf06917e2010-02-02 23:00:29 +0000913str, bytes.
Georg Brandl116aa622007-08-15 14:28:22 +0000914
Georg Brandl116aa622007-08-15 14:28:22 +0000915There are two ways to enable the :mod:`sqlite3` module to adapt a custom Python
916type to one of the supported ones.
917
918
919Letting your object adapt itself
920""""""""""""""""""""""""""""""""
921
922This is a good approach if you write the class yourself. Let's suppose you have
923a class like this::
924
Éric Araujo28053fb2010-11-22 03:09:19 +0000925 class Point:
Georg Brandl116aa622007-08-15 14:28:22 +0000926 def __init__(self, x, y):
927 self.x, self.y = x, y
928
929Now you want to store the point in a single SQLite column. First you'll have to
930choose one of the supported types first to be used for representing the point.
931Let's just use str and separate the coordinates using a semicolon. Then you need
932to give your class a method ``__conform__(self, protocol)`` which must return
933the converted value. The parameter *protocol* will be :class:`PrepareProtocol`.
934
935.. literalinclude:: ../includes/sqlite3/adapter_point_1.py
936
937
938Registering an adapter callable
939"""""""""""""""""""""""""""""""
940
941The other possibility is to create a function that converts the type to the
942string representation and register the function with :meth:`register_adapter`.
943
Georg Brandl116aa622007-08-15 14:28:22 +0000944.. literalinclude:: ../includes/sqlite3/adapter_point_2.py
945
946The :mod:`sqlite3` module has two default adapters for Python's built-in
947:class:`datetime.date` and :class:`datetime.datetime` types. Now let's suppose
948we want to store :class:`datetime.datetime` objects not in ISO representation,
949but as a Unix timestamp.
950
951.. literalinclude:: ../includes/sqlite3/adapter_datetime.py
952
953
954Converting SQLite values to custom Python types
955^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
956
957Writing an adapter lets you send custom Python types to SQLite. But to make it
958really useful we need to make the Python to SQLite to Python roundtrip work.
959
960Enter converters.
961
962Let's go back to the :class:`Point` class. We stored the x and y coordinates
963separated via semicolons as strings in SQLite.
964
965First, we'll define a converter function that accepts the string as a parameter
966and constructs a :class:`Point` object from it.
967
968.. note::
969
Zachary Ware9d085622014-04-01 12:21:56 -0500970 Converter functions **always** get called with a :class:`bytes` object, no
971 matter under which data type you sent the value to SQLite.
Georg Brandl116aa622007-08-15 14:28:22 +0000972
Georg Brandl116aa622007-08-15 14:28:22 +0000973::
974
975 def convert_point(s):
Petri Lehtinen1ca93952012-02-15 22:17:21 +0200976 x, y = map(float, s.split(b";"))
Georg Brandl116aa622007-08-15 14:28:22 +0000977 return Point(x, y)
978
979Now you need to make the :mod:`sqlite3` module know that what you select from
980the database is actually a point. There are two ways of doing this:
981
982* Implicitly via the declared type
983
984* Explicitly via the column name
985
986Both ways are described in section :ref:`sqlite3-module-contents`, in the entries
987for the constants :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`.
988
989The following example illustrates both approaches.
990
991.. literalinclude:: ../includes/sqlite3/converter_point.py
992
993
994Default adapters and converters
995^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
996
997There are default adapters for the date and datetime types in the datetime
998module. They will be sent as ISO dates/ISO timestamps to SQLite.
999
1000The default converters are registered under the name "date" for
1001:class:`datetime.date` and under the name "timestamp" for
1002:class:`datetime.datetime`.
1003
1004This way, you can use date/timestamps from Python without any additional
1005fiddling in most cases. The format of the adapters is also compatible with the
1006experimental SQLite date/time functions.
1007
1008The following example demonstrates this.
1009
1010.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py
1011
Petri Lehtinen5f794092013-02-26 21:32:02 +02001012If a timestamp stored in SQLite has a fractional part longer than 6
1013numbers, its value will be truncated to microsecond precision by the
1014timestamp converter.
1015
Georg Brandl116aa622007-08-15 14:28:22 +00001016
1017.. _sqlite3-controlling-transactions:
1018
1019Controlling Transactions
1020------------------------
1021
Berker Peksaga71fed02018-07-29 12:01:38 +03001022The underlying ``sqlite3`` library operates in ``autocommit`` mode by default,
1023but the Python :mod:`sqlite3` module by default does not.
1024
1025``autocommit`` mode means that statements that modify the database take effect
1026immediately. A ``BEGIN`` or ``SAVEPOINT`` statement disables ``autocommit``
1027mode, and a ``COMMIT``, a ``ROLLBACK``, or a ``RELEASE`` that ends the
1028outermost transaction, turns ``autocommit`` mode back on.
1029
1030The Python :mod:`sqlite3` module by default issues a ``BEGIN`` statement
1031implicitly before a Data Modification Language (DML) statement (i.e.
Berker Peksagab994ed2016-09-11 12:57:15 +03001032``INSERT``/``UPDATE``/``DELETE``/``REPLACE``).
Georg Brandl116aa622007-08-15 14:28:22 +00001033
Berker Peksaga71fed02018-07-29 12:01:38 +03001034You can control which kind of ``BEGIN`` statements :mod:`sqlite3` implicitly
1035executes via the *isolation_level* parameter to the :func:`connect`
Georg Brandl116aa622007-08-15 14:28:22 +00001036call, or via the :attr:`isolation_level` property of connections.
Berker Peksaga71fed02018-07-29 12:01:38 +03001037If you specify no *isolation_level*, a plain ``BEGIN`` is used, which is
1038equivalent to specifying ``DEFERRED``. Other possible values are ``IMMEDIATE``
1039and ``EXCLUSIVE``.
Georg Brandl116aa622007-08-15 14:28:22 +00001040
Berker Peksaga71fed02018-07-29 12:01:38 +03001041You can disable the :mod:`sqlite3` module's implicit transaction management by
1042setting :attr:`isolation_level` to ``None``. This will leave the underlying
1043``sqlite3`` library operating in ``autocommit`` mode. You can then completely
1044control the transaction state by explicitly issuing ``BEGIN``, ``ROLLBACK``,
1045``SAVEPOINT``, and ``RELEASE`` statements in your code.
Berker Peksagfe70d922017-02-26 18:31:12 +03001046
Berker Peksagab994ed2016-09-11 12:57:15 +03001047.. versionchanged:: 3.6
1048 :mod:`sqlite3` used to implicitly commit an open transaction before DDL
1049 statements. This is no longer the case.
Georg Brandl116aa622007-08-15 14:28:22 +00001050
1051
Georg Brandl8a1e4c42009-05-25 21:13:36 +00001052Using :mod:`sqlite3` efficiently
1053--------------------------------
Georg Brandl116aa622007-08-15 14:28:22 +00001054
1055
1056Using shortcut methods
1057^^^^^^^^^^^^^^^^^^^^^^
1058
1059Using the nonstandard :meth:`execute`, :meth:`executemany` and
1060:meth:`executescript` methods of the :class:`Connection` object, your code can
1061be written more concisely because you don't have to create the (often
1062superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
1063objects are created implicitly and these shortcut methods return the cursor
Benjamin Petersonf10a79a2008-10-11 00:49:57 +00001064objects. This way, you can execute a ``SELECT`` statement and iterate over it
Georg Brandl116aa622007-08-15 14:28:22 +00001065directly using only a single call on the :class:`Connection` object.
1066
1067.. literalinclude:: ../includes/sqlite3/shortcut_methods.py
1068
1069
1070Accessing columns by name instead of by index
1071^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1072
Georg Brandl22b34312009-07-26 14:54:51 +00001073One useful feature of the :mod:`sqlite3` module is the built-in
Georg Brandl116aa622007-08-15 14:28:22 +00001074:class:`sqlite3.Row` class designed to be used as a row factory.
1075
1076Rows wrapped with this class can be accessed both by index (like tuples) and
1077case-insensitively by name:
1078
1079.. literalinclude:: ../includes/sqlite3/rowclass.py
1080
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +00001081
1082Using the connection as a context manager
1083^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1084
Gerhard Häring0d7d6cf2008-03-29 01:32:44 +00001085Connection objects can be used as context managers
1086that automatically commit or rollback transactions. In the event of an
1087exception, the transaction is rolled back; otherwise, the transaction is
1088committed:
1089
1090.. literalinclude:: ../includes/sqlite3/ctx_manager.py
Gerhard Häringc34d76c2010-08-06 06:12:05 +00001091
1092
1093Common issues
1094-------------
1095
1096Multithreading
1097^^^^^^^^^^^^^^
1098
1099Older SQLite versions had issues with sharing connections between threads.
1100That's why the Python module disallows sharing connections and cursors between
1101threads. If you still try to do so, you will get an exception at runtime.
1102
1103The only exception is calling the :meth:`~Connection.interrupt` method, which
1104only makes sense to call from a different thread.
1105
Gerhard Häringe0941c52010-10-03 21:47:06 +00001106.. rubric:: Footnotes
1107
1108.. [#f1] The sqlite3 module is not built with loadable extension support by
Senthil Kumaran946eb862011-07-03 10:17:22 -07001109 default, because some platforms (notably Mac OS X) have SQLite
1110 libraries which are compiled without this feature. To get loadable
1111 extension support, you must pass --enable-loadable-sqlite-extensions to
1112 configure.