1:mod:`sqlite3` --- DB-API 2.0 interface for SQLite databases
2============================================================
3
4.. module:: sqlite3
5   :synopsis: A DB-API 2.0 implementation using SQLite 3.x.
6
7.. sectionauthor:: Gerhard Häring <[email protected]>
8
9**Source code:** :source:`Lib/sqlite3/`
10
11.. Make sure we always doctest the tutorial with an empty database.
12
13.. testsetup::
14
15   import sqlite3
16   src = sqlite3.connect(":memory:", isolation_level=None)
17   dst = sqlite3.connect("tutorial.db", isolation_level=None)
18   src.backup(dst)
19   del src, dst
20
21.. _sqlite3-intro:
22
23SQLite is a C library that provides a lightweight disk-based database that
24doesn't require a separate server process and allows accessing the database
25using a nonstandard variant of the SQL query language. Some applications can use
26SQLite for internal data storage.  It's also possible to prototype an
27application using SQLite and then port the code to a larger database such as
28PostgreSQL or Oracle.
29
30The :mod:`!sqlite3` module was written by Gerhard Häring.  It provides an SQL interface
31compliant with the DB-API 2.0 specification described by :pep:`249`, and
32requires SQLite 3.7.15 or newer.
33
34This document includes four main sections:
35
36* :ref:`sqlite3-tutorial` teaches how to use the :mod:`!sqlite3` module.
37* :ref:`sqlite3-reference` describes the classes and functions this module
38  defines.
39* :ref:`sqlite3-howtos` details how to handle specific tasks.
40* :ref:`sqlite3-explanation` provides in-depth background on
41  transaction control.
42
43.. seealso::
44
45   https://www.sqlite.org
46      The SQLite web page; the documentation describes the syntax and the
47      available data types for the supported SQL dialect.
48
49   https://www.w3schools.com/sql/
50      Tutorial, reference and examples for learning SQL syntax.
51
52   :pep:`249` - Database API Specification 2.0
53      PEP written by Marc-André Lemburg.
54
55
56.. We use the following practises for SQL code:
57   - UPPERCASE for keywords
58   - snake_case for schema
59   - single quotes for string literals
60   - singular for table names
61   - if needed, use double quotes for table and column names
62
63.. _sqlite3-tutorial:
64
65Tutorial
66--------
67
68In this tutorial, you will create a database of Monty Python movies
69using basic :mod:`!sqlite3` functionality.
70It assumes a fundamental understanding of database concepts,
71including `cursors`_ and `transactions`_.
72
73First, we need to create a new database and open
74a database connection to allow :mod:`!sqlite3` to work with it.
75Call :func:`sqlite3.connect` to create a connection to
76the database :file:`tutorial.db` in the current working directory,
77implicitly creating it if it does not exist:
78
79.. testcode::
80
81   import sqlite3
82   con = sqlite3.connect("tutorial.db")
83
84The returned :class:`Connection` object ``con``
85represents the connection to the on-disk database.
86
87In order to execute SQL statements and fetch results from SQL queries,
88we will need to use a database cursor.
89Call :meth:`con.cursor() <Connection.cursor>` to create the :class:`Cursor`:
90
91.. testcode::
92
93   cur = con.cursor()
94
95Now that we've got a database connection and a cursor,
96we can create a database table ``movie`` with columns for title,
97release year, and review score.
98For simplicity, we can just use column names in the table declaration --
99thanks to the `flexible typing`_ feature of SQLite,
100specifying the data types is optional.
101Execute the ``CREATE TABLE`` statement
102by calling :meth:`cur.execute(...) <Cursor.execute>`:
103
104.. testcode::
105
106   cur.execute("CREATE TABLE movie(title, year, score)")
107
108.. Ideally, we'd use sqlite_schema instead of sqlite_master below,
109   but SQLite versions older than 3.33.0 do not recognise that variant.
110
111We can verify that the new table has been created by querying
112the ``sqlite_master`` table built-in to SQLite,
113which should now contain an entry for the ``movie`` table definition
114(see `The Schema Table`_ for details).
115Execute that query by calling :meth:`cur.execute(...) <Cursor.execute>`,
116assign the result to ``res``,
117and call :meth:`res.fetchone() <Cursor.fetchone>` to fetch the resulting row:
118
119.. doctest::
120
121   >>> res = cur.execute("SELECT name FROM sqlite_master")
122   >>> res.fetchone()
123   ('movie',)
124
125We can see that the table has been created,
126as the query returns a :class:`tuple` containing the table's name.
127If we query ``sqlite_master`` for a non-existent table ``spam``,
128:meth:`!res.fetchone()` will return ``None``:
129
130.. doctest::
131
132   >>> res = cur.execute("SELECT name FROM sqlite_master WHERE name='spam'")
133   >>> res.fetchone() is None
134   True
135
136Now, add two rows of data supplied as SQL literals
137by executing an ``INSERT`` statement,
138once again by calling :meth:`cur.execute(...) <Cursor.execute>`:
139
140.. testcode::
141
142   cur.execute("""
143       INSERT INTO movie VALUES
144           ('Monty Python and the Holy Grail', 1975, 8.2),
145           ('And Now for Something Completely Different', 1971, 7.5)
146   """)
147
148The ``INSERT`` statement implicitly opens a transaction,
149which needs to be committed before changes are saved in the database
150(see :ref:`sqlite3-controlling-transactions` for details).
151Call :meth:`con.commit() <Connection.commit>` on the connection object
152to commit the transaction:
153
154.. testcode::
155
156   con.commit()
157
158We can verify that the data was inserted correctly
159by executing a ``SELECT`` query.
160Use the now-familiar :meth:`cur.execute(...) <Cursor.execute>` to
161assign the result to ``res``,
162and call :meth:`res.fetchall() <Cursor.fetchall>` to return all resulting rows:
163
164.. doctest::
165
166   >>> res = cur.execute("SELECT score FROM movie")
167   >>> res.fetchall()
168   [(8.2,), (7.5,)]
169
170The result is a :class:`list` of two :class:`!tuple`\s, one per row,
171each containing that row's ``score`` value.
172
173Now, insert three more rows by calling
174:meth:`cur.executemany(...) <Cursor.executemany>`:
175
176.. testcode::
177
178   data = [
179       ("Monty Python Live at the Hollywood Bowl", 1982, 7.9),
180       ("Monty Python's The Meaning of Life", 1983, 7.5),
181       ("Monty Python's Life of Brian", 1979, 8.0),
182   ]
183   cur.executemany("INSERT INTO movie VALUES(?, ?, ?)", data)
184   con.commit()  # Remember to commit the transaction after executing INSERT.
185
186Notice that ``?`` placeholders are used to bind ``data`` to the query.
187Always use placeholders instead of :ref:`string formatting <tut-formatting>`
188to bind Python values to SQL statements,
189to avoid `SQL injection attacks`_
190(see :ref:`sqlite3-placeholders` for more details).
191
192We can verify that the new rows were inserted
193by executing a ``SELECT`` query,
194this time iterating over the results of the query:
195
196.. doctest::
197
198   >>> for row in cur.execute("SELECT year, title FROM movie ORDER BY year"):
199   ...     print(row)
200   (1971, 'And Now for Something Completely Different')
201   (1975, 'Monty Python and the Holy Grail')
202   (1979, "Monty Python's Life of Brian")
203   (1982, 'Monty Python Live at the Hollywood Bowl')
204   (1983, "Monty Python's The Meaning of Life")
205
206Each row is a two-item :class:`tuple` of ``(year, title)``,
207matching the columns selected in the query.
208
209Finally, verify that the database has been written to disk
210by calling :meth:`con.close() <Connection.close>`
211to close the existing connection, opening a new one,
212creating a new cursor, then querying the database:
213
214.. doctest::
215
216   >>> con.close()
217   >>> new_con = sqlite3.connect("tutorial.db")
218   >>> new_cur = new_con.cursor()
219   >>> res = new_cur.execute("SELECT title, year FROM movie ORDER BY score DESC")
220   >>> title, year = res.fetchone()
221   >>> print(f'The highest scoring Monty Python movie is {title!r}, released in {year}')
222   The highest scoring Monty Python movie is 'Monty Python and the Holy Grail', released in 1975
223
224You've now created an SQLite database using the :mod:`!sqlite3` module,
225inserted data and retrieved values from it in multiple ways.
226
227.. _SQL injection attacks: https://en.wikipedia.org/wiki/SQL_injection
228.. _The Schema Table: https://www.sqlite.org/schematab.html
229.. _cursors: https://en.wikipedia.org/wiki/Cursor_(databases)
230.. _flexible typing: https://www.sqlite.org/flextypegood.html
231.. _sqlite_master: https://www.sqlite.org/schematab.html
232.. _transactions: https://en.wikipedia.org/wiki/Database_transaction
233
234.. seealso::
235
236   * :ref:`sqlite3-howtos` for further reading:
237
238      * :ref:`sqlite3-placeholders`
239      * :ref:`sqlite3-adapters`
240      * :ref:`sqlite3-converters`
241      * :ref:`sqlite3-connection-context-manager`
242      * :ref:`sqlite3-howto-row-factory`
243
244   * :ref:`sqlite3-explanation` for in-depth background on transaction control.
245
246.. _sqlite3-reference:
247
248Reference
249---------
250
251.. We keep the old sqlite3-module-contents ref to prevent breaking links.
252.. _sqlite3-module-contents:
253
254.. _sqlite3-module-functions:
255
256Module functions
257^^^^^^^^^^^^^^^^
258
259.. function:: connect(database, timeout=5.0, detect_types=0, \
260                      isolation_level="DEFERRED", check_same_thread=True, \
261                      factory=sqlite3.Connection, cached_statements=128, \
262                      uri=False)
263
264   Open a connection to an SQLite database.
265
266   :param database:
267       The path to the database file to be opened.
268       Pass ``":memory:"`` to open a connection to a database that is
269       in RAM instead of on disk.
270   :type database: :term:`path-like object`
271
272   :param float timeout:
273       How many seconds the connection should wait before raising
274       an :exc:`OperationalError` when a table is locked.
275       If another connection opens a transaction to modify a table,
276       that table will be locked until the transaction is committed.
277       Default five seconds.
278
279   :param int detect_types:
280       Control whether and how data types not
281       :ref:`natively supported by SQLite <sqlite3-types>`
282       are looked up to be converted to Python types,
283       using the converters registered with :func:`register_converter`.
284       Set it to any combination (using ``|``, bitwise or) of
285       :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`
286       to enable this.
287       Column names takes precedence over declared types if both flags are set.
288       Types cannot be detected for generated fields (for example ``max(data)``),
289       even when the *detect_types* parameter is set; :class:`str` will be
290       returned instead.
291       By default (``0``), type detection is disabled.
292
293   :param isolation_level:
294       The :attr:`~Connection.isolation_level` of the connection,
295       controlling whether and how transactions are implicitly opened.
296       Can be ``"DEFERRED"`` (default), ``"EXCLUSIVE"`` or ``"IMMEDIATE"``;
297       or ``None`` to disable opening transactions implicitly.
298       See :ref:`sqlite3-controlling-transactions` for more.
299   :type isolation_level: str | None
300
301   :param bool check_same_thread:
302       If ``True`` (default), :exc:`ProgrammingError` will be raised
303       if the database connection is used by a thread
304       other than the one that created it.
305       If ``False``, the connection may be accessed in multiple threads;
306       write operations may need to be serialized by the user
307       to avoid data corruption.
308       See :attr:`threadsafety` for more information.
309
310   :param ~sqlite3.Connection factory:
311       A custom subclass of :class:`Connection` to create the connection with,
312       if not the default :class:`Connection` class.
313
314   :param int cached_statements:
315       The number of statements that :mod:`!sqlite3`
316       should internally cache for this connection, to avoid parsing overhead.
317       By default, 128 statements.
318
319   :param bool uri:
320       If set to ``True``, *database* is interpreted as a
321       :abbr:`URI (Uniform Resource Identifier)` with a file path
322       and an optional query string.
323       The scheme part *must* be ``"file:"``,
324       and the path can be relative or absolute.
325       The query string allows passing parameters to SQLite,
326       enabling various :ref:`sqlite3-uri-tricks`.
327
328   :rtype: ~sqlite3.Connection
329
330   .. audit-event:: sqlite3.connect database sqlite3.connect
331   .. audit-event:: sqlite3.connect/handle connection_handle sqlite3.connect
332
333   .. versionadded:: 3.4
334      The *uri* parameter.
335
336   .. versionchanged:: 3.7
337      *database* can now also be a :term:`path-like object`, not only a string.
338
339   .. versionadded:: 3.10
340      The ``sqlite3.connect/handle`` auditing event.
341
342.. function:: complete_statement(statement)
343
344   Return ``True`` if the string *statement* appears to contain
345   one or more complete SQL statements.
346   No syntactic verification or parsing of any kind is performed,
347   other than checking that there are no unclosed string literals
348   and the statement is terminated by a semicolon.
349
350   For example:
351
352   .. doctest::
353
354      >>> sqlite3.complete_statement("SELECT foo FROM bar;")
355      True
356      >>> sqlite3.complete_statement("SELECT foo")
357      False
358
359   This function may be useful during command-line input
360   to determine if the entered text seems to form a complete SQL statement,
361   or if additional input is needed before calling :meth:`~Cursor.execute`.
362
363.. function:: enable_callback_tracebacks(flag, /)
364
365   Enable or disable callback tracebacks.
366   By default you will not get any tracebacks in user-defined functions,
367   aggregates, converters, authorizer callbacks etc. If you want to debug them,
368   you can call this function with *flag* set to ``True``. Afterwards, you
369   will get tracebacks from callbacks on :data:`sys.stderr`. Use ``False``
370   to disable the feature again.
371
372   Register an :func:`unraisable hook handler <sys.unraisablehook>` for an
373   improved debug experience:
374
375   .. testsetup:: sqlite3.trace
376
377      import sqlite3
378
379   .. doctest:: sqlite3.trace
380
381      >>> sqlite3.enable_callback_tracebacks(True)
382      >>> con = sqlite3.connect(":memory:")
383      >>> def evil_trace(stmt):
384      ...     5/0
385      >>> con.set_trace_callback(evil_trace)
386      >>> def debug(unraisable):
387      ...     print(f"{unraisable.exc_value!r} in callback {unraisable.object.__name__}")
388      ...     print(f"Error message: {unraisable.err_msg}")
389      >>> import sys
390      >>> sys.unraisablehook = debug
391      >>> cur = con.execute("SELECT 1")
392      ZeroDivisionError('division by zero') in callback evil_trace
393      Error message: None
394
395.. function:: register_adapter(type, adapter, /)
396
397   Register an *adapter* callable to adapt the Python type *type* into an
398   SQLite type.
399   The adapter is called with a Python object of type *type* as its sole
400   argument, and must return a value of a
401   :ref:`type that SQLite natively understands <sqlite3-types>`.
402
403.. function:: register_converter(typename, converter, /)
404
405   Register the *converter* callable to convert SQLite objects of type
406   *typename* into a Python object of a specific type.
407   The converter is invoked for all SQLite values of type *typename*;
408   it is passed a :class:`bytes` object and should return an object of the
409   desired Python type.
410   Consult the parameter *detect_types* of
411   :func:`connect` for information regarding how type detection works.
412
413   Note: *typename* and the name of the type in your query are matched
414   case-insensitively.
415
416
417.. _sqlite3-module-constants:
418
419Module constants
420^^^^^^^^^^^^^^^^
421
422.. data:: PARSE_COLNAMES
423
424   Pass this flag value to the *detect_types* parameter of
425   :func:`connect` to look up a converter function by
426   using the type name, parsed from the query column name,
427   as the converter dictionary key.
428   The type name must be wrapped in square brackets (``[]``).
429
430   .. code-block:: sql
431
432      SELECT p as "p [point]" FROM test;  ! will look up converter "point"
433
434   This flag may be combined with :const:`PARSE_DECLTYPES` using the ``|``
435   (bitwise or) operator.
436
437.. data:: PARSE_DECLTYPES
438
439   Pass this flag value to the *detect_types* parameter of
440   :func:`connect` to look up a converter function using
441   the declared types for each column.
442   The types are declared when the database table is created.
443   :mod:`!sqlite3` will look up a converter function using the first word of the
444   declared type as the converter dictionary key.
445   For example:
446
447   .. code-block:: sql
448
449      CREATE TABLE test(
450         i integer primary key,  ! will look up a converter named "integer"
451         p point,                ! will look up a converter named "point"
452         n number(10)            ! will look up a converter named "number"
453       )
454
455   This flag may be combined with :const:`PARSE_COLNAMES` using the ``|``
456   (bitwise or) operator.
457
458.. data:: SQLITE_OK
459          SQLITE_DENY
460          SQLITE_IGNORE
461
462   Flags that should be returned by the *authorizer_callback* callable
463   passed to :meth:`Connection.set_authorizer`, to indicate whether:
464
465   * Access is allowed (:const:`!SQLITE_OK`),
466   * The SQL statement should be aborted with an error (:const:`!SQLITE_DENY`)
467   * The column should be treated as a ``NULL`` value (:const:`!SQLITE_IGNORE`)
468
469.. data:: apilevel
470
471   String constant stating the supported DB-API level. Required by the DB-API.
472   Hard-coded to ``"2.0"``.
473
474.. data:: paramstyle
475
476   String constant stating the type of parameter marker formatting expected by
477   the :mod:`!sqlite3` module. Required by the DB-API. Hard-coded to
478   ``"qmark"``.
479
480   .. note::
481
482      The ``named`` DB-API parameter style is also supported.
483
484.. data:: sqlite_version
485
486   Version number of the runtime SQLite library as a :class:`string <str>`.
487
488.. data:: sqlite_version_info
489
490   Version number of the runtime SQLite library as a :class:`tuple` of
491   :class:`integers <int>`.
492
493.. data:: threadsafety
494
495   Integer constant required by the DB-API 2.0, stating the level of thread
496   safety the :mod:`!sqlite3` module supports. This attribute is set based on
497   the default `threading mode <https://sqlite.org/threadsafe.html>`_ the
498   underlying SQLite library is compiled with. The SQLite threading modes are:
499
500     1. **Single-thread**: In this mode, all mutexes are disabled and SQLite is
501        unsafe to use in more than a single thread at once.
502     2. **Multi-thread**: In this mode, SQLite can be safely used by multiple
503        threads provided that no single database connection is used
504        simultaneously in two or more threads.
505     3. **Serialized**: In serialized mode, SQLite can be safely used by
506        multiple threads with no restriction.
507
508   The mappings from SQLite threading modes to DB-API 2.0 threadsafety levels
509   are as follows:
510
511   +------------------+-----------------+----------------------+-------------------------------+
512   | SQLite threading | `threadsafety`_ | `SQLITE_THREADSAFE`_ | DB-API 2.0 meaning            |
513   | mode             |                 |                      |                               |
514   +==================+=================+======================+===============================+
515   | single-thread    | 0               | 0                    | Threads may not share the     |
516   |                  |                 |                      | module                        |
517   +------------------+-----------------+----------------------+-------------------------------+
518   | multi-thread     | 1               | 2                    | Threads may share the module, |
519   |                  |                 |                      | but not connections           |
520   +------------------+-----------------+----------------------+-------------------------------+
521   | serialized       | 3               | 1                    | Threads may share the module, |
522   |                  |                 |                      | connections and cursors       |
523   +------------------+-----------------+----------------------+-------------------------------+
524
525   .. _threadsafety: https://peps.python.org/pep-0249/#threadsafety
526   .. _SQLITE_THREADSAFE: https://sqlite.org/compile.html#threadsafe
527
528   .. versionchanged:: 3.11
529      Set *threadsafety* dynamically instead of hard-coding it to ``1``.
530
531.. data:: version
532
533   Version number of this module as a :class:`string <str>`.
534   This is not the version of the SQLite library.
535
536.. data:: version_info
537
538   Version number of this module as a :class:`tuple` of :class:`integers <int>`.
539   This is not the version of the SQLite library.
540
541
542.. _sqlite3-connection-objects:
543
544Connection objects
545^^^^^^^^^^^^^^^^^^
546
547.. class:: Connection
548
549   Each open SQLite database is represented by a ``Connection`` object,
550   which is created using :func:`sqlite3.connect`.
551   Their main purpose is creating :class:`Cursor` objects,
552   and :ref:`sqlite3-controlling-transactions`.
553
554   .. seealso::
555
556      * :ref:`sqlite3-connection-shortcuts`
557      * :ref:`sqlite3-connection-context-manager`
558
559   An SQLite database connection has the following attributes and methods:
560
561   .. method:: cursor(factory=Cursor)
562
563      Create and return a :class:`Cursor` object.
564      The cursor method accepts a single optional parameter *factory*. If
565      supplied, this must be a callable returning an instance of :class:`Cursor`
566      or its subclasses.
567
568   .. method:: blobopen(table, column, row, /, *, readonly=False, name="main")
569
570      Open a :class:`Blob` handle to an existing
571      :abbr:`BLOB (Binary Large OBject)`.
572
573      :param str table:
574          The name of the table where the blob is located.
575
576      :param str column:
577          The name of the column where the blob is located.
578
579      :param str row:
580          The name of the row where the blob is located.
581
582      :param bool readonly:
583          Set to ``True`` if the blob should be opened without write
584          permissions.
585          Defaults to ``False``.
586
587      :param str name:
588          The name of the database where the blob is located.
589          Defaults to ``"main"``.
590
591      :raises OperationalError:
592          When trying to open a blob in a ``WITHOUT ROWID`` table.
593
594      :rtype: Blob
595
596      .. note::
597
598         The blob size cannot be changed using the :class:`Blob` class.
599         Use the SQL function ``zeroblob`` to create a blob with a fixed size.
600
601      .. versionadded:: 3.11
602
603   .. method:: commit()
604
605      Commit any pending transaction to the database.
606      If there is no open transaction, this method is a no-op.
607
608   .. method:: rollback()
609
610      Roll back to the start of any pending transaction.
611      If there is no open transaction, this method is a no-op.
612
613   .. method:: close()
614
615      Close the database connection.
616      Any pending transaction is not committed implicitly;
617      make sure to :meth:`commit` before closing
618      to avoid losing pending changes.
619
620   .. method:: execute(sql, parameters=(), /)
621
622      Create a new :class:`Cursor` object and call
623      :meth:`~Cursor.execute` on it with the given *sql* and *parameters*.
624      Return the new cursor object.
625
626   .. method:: executemany(sql, parameters, /)
627
628      Create a new :class:`Cursor` object and call
629      :meth:`~Cursor.executemany` on it with the given *sql* and *parameters*.
630      Return the new cursor object.
631
632   .. method:: executescript(sql_script, /)
633
634      Create a new :class:`Cursor` object and call
635      :meth:`~Cursor.executescript` on it with the given *sql_script*.
636      Return the new cursor object.
637
638   .. method:: create_function(name, narg, func, *, deterministic=False)
639
640      Create or remove a user-defined SQL function.
641
642      :param str name:
643          The name of the SQL function.
644
645      :param int narg:
646          The number of arguments the SQL function can accept.
647          If ``-1``, it may take any number of arguments.
648
649      :param func:
650          A callable that is called when the SQL function is invoked.
651          The callable must return :ref:`a type natively supported by SQLite
652          <sqlite3-types>`.
653          Set to ``None`` to remove an existing SQL function.
654      :type func: :term:`callback` | None
655
656      :param bool deterministic:
657          If ``True``, the created SQL function is marked as
658          `deterministic <https://sqlite.org/deterministic.html>`_,
659          which allows SQLite to perform additional optimizations.
660
661      :raises NotSupportedError:
662          If *deterministic* is used with SQLite versions older than 3.8.3.
663
664      .. versionadded:: 3.8
665         The *deterministic* parameter.
666
667      Example:
668
669      .. doctest::
670
671         >>> import hashlib
672         >>> def md5sum(t):
673         ...     return hashlib.md5(t).hexdigest()
674         >>> con = sqlite3.connect(":memory:")
675         >>> con.create_function("md5", 1, md5sum)
676         >>> for row in con.execute("SELECT md5(?)", (b"foo",)):
677         ...     print(row)
678         ('acbd18db4cc2f85cedef654fccc4a4d8',)
679
680
681   .. method:: create_aggregate(name, /, n_arg, aggregate_class)
682
683      Create or remove a user-defined SQL aggregate function.
684
685      :param str name:
686          The name of the SQL aggregate function.
687
688      :param int n_arg:
689          The number of arguments the SQL aggregate function can accept.
690          If ``-1``, it may take any number of arguments.
691
692      :param aggregate_class:
693          A class must implement the following methods:
694
695          * ``step()``: Add a row to the aggregate.
696          * ``finalize()``: Return the final result of the aggregate as
697            :ref:`a type natively supported by SQLite <sqlite3-types>`.
698
699          The number of arguments that the ``step()`` method must accept
700          is controlled by *n_arg*.
701
702          Set to ``None`` to remove an existing SQL aggregate function.
703      :type aggregate_class: :term:`class` | None
704
705      Example:
706
707      .. testcode::
708
709         class MySum:
710             def __init__(self):
711                 self.count = 0
712
713             def step(self, value):
714                 self.count += value
715
716             def finalize(self):
717                 return self.count
718
719         con = sqlite3.connect(":memory:")
720         con.create_aggregate("mysum", 1, MySum)
721         cur = con.execute("CREATE TABLE test(i)")
722         cur.execute("INSERT INTO test(i) VALUES(1)")
723         cur.execute("INSERT INTO test(i) VALUES(2)")
724         cur.execute("SELECT mysum(i) FROM test")
725         print(cur.fetchone()[0])
726
727         con.close()
728
729      .. testoutput::
730         :hide:
731
732         3
733
734
735   .. method:: create_window_function(name, num_params, aggregate_class, /)
736
737      Create or remove a user-defined aggregate window function.
738
739      :param str name:
740          The name of the SQL aggregate window function to create or remove.
741
742      :param int num_params:
743          The number of arguments the SQL aggregate window function can accept.
744          If ``-1``, it may take any number of arguments.
745
746      :param aggregate_class:
747          A class that must implement the following methods:
748
749          * ``step()``: Add a row to the current window.
750          * ``value()``: Return the current value of the aggregate.
751          * ``inverse()``: Remove a row from the current window.
752          * ``finalize()``: Return the final result of the aggregate as
753            :ref:`a type natively supported by SQLite <sqlite3-types>`.
754
755          The number of arguments that the ``step()`` and ``value()`` methods
756          must accept is controlled by *num_params*.
757
758          Set to ``None`` to remove an existing SQL aggregate window function.
759
760      :raises NotSupportedError:
761          If used with a version of SQLite older than 3.25.0,
762          which does not support aggregate window functions.
763
764      :type aggregate_class: :term:`class` | None
765
766      .. versionadded:: 3.11
767
768      Example:
769
770      .. testcode::
771
772         # Example taken from https://www.sqlite.org/windowfunctions.html#udfwinfunc
773         class WindowSumInt:
774             def __init__(self):
775                 self.count = 0
776
777             def step(self, value):
778                 """Add a row to the current window."""
779                 self.count += value
780
781             def value(self):
782                 """Return the current value of the aggregate."""
783                 return self.count
784
785             def inverse(self, value):
786                 """Remove a row from the current window."""
787                 self.count -= value
788
789             def finalize(self):
790                 """Return the final value of the aggregate.
791
792                 Any clean-up actions should be placed here.
793                 """
794                 return self.count
795
796
797         con = sqlite3.connect(":memory:")
798         cur = con.execute("CREATE TABLE test(x, y)")
799         values = [
800             ("a", 4),
801             ("b", 5),
802             ("c", 3),
803             ("d", 8),
804             ("e", 1),
805         ]
806         cur.executemany("INSERT INTO test VALUES(?, ?)", values)
807         con.create_window_function("sumint", 1, WindowSumInt)
808         cur.execute("""
809             SELECT x, sumint(y) OVER (
810                 ORDER BY x ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING
811             ) AS sum_y
812             FROM test ORDER BY x
813         """)
814         print(cur.fetchall())
815
816      .. testoutput::
817         :hide:
818
819         [('a', 9), ('b', 12), ('c', 16), ('d', 12), ('e', 9)]
820
821   .. method:: create_collation(name, callable)
822
823      Create a collation named *name* using the collating function *callable*.
824      *callable* is passed two :class:`string <str>` arguments,
825      and it should return an :class:`integer <int>`:
826
827      * ``1`` if the first is ordered higher than the second
828      * ``-1`` if the first is ordered lower than the second
829      * ``0`` if they are ordered equal
830
831      The following example shows a reverse sorting collation:
832
833      .. testcode::
834
835         def collate_reverse(string1, string2):
836             if string1 == string2:
837                 return 0
838             elif string1 < string2:
839                 return 1
840             else:
841                 return -1
842
843         con = sqlite3.connect(":memory:")
844         con.create_collation("reverse", collate_reverse)
845
846         cur = con.execute("CREATE TABLE test(x)")
847         cur.executemany("INSERT INTO test(x) VALUES(?)", [("a",), ("b",)])
848         cur.execute("SELECT x FROM test ORDER BY x COLLATE reverse")
849         for row in cur:
850             print(row)
851         con.close()
852
853      .. testoutput::
854         :hide:
855
856         ('b',)
857         ('a',)
858
859      Remove a collation function by setting *callable* to ``None``.
860
861      .. versionchanged:: 3.11
862         The collation name can contain any Unicode character.  Earlier, only
863         ASCII characters were allowed.
864
865
866   .. method:: interrupt()
867
868      Call this method from a different thread to abort any queries that might
869      be executing on the connection.
870      Aborted queries will raise an :exc:`OperationalError`.
871
872
873   .. method:: set_authorizer(authorizer_callback)
874
875      Register callable *authorizer_callback* to be invoked for each attempt to
876      access a column of a table in the database. The callback should return
877      one of :const:`SQLITE_OK`, :const:`SQLITE_DENY`, or :const:`SQLITE_IGNORE`
878      to signal how access to the column should be handled
879      by the underlying SQLite library.
880
881      The first argument to the callback signifies what kind of operation is to be
882      authorized. The second and third argument will be arguments or ``None``
883      depending on the first argument. The 4th argument is the name of the database
884      ("main", "temp", etc.) if applicable. The 5th argument is the name of the
885      inner-most trigger or view that is responsible for the access attempt or
886      ``None`` if this access attempt is directly from input SQL code.
887
888      Please consult the SQLite documentation about the possible values for the first
889      argument and the meaning of the second and third argument depending on the first
890      one. All necessary constants are available in the :mod:`!sqlite3` module.
891
892      Passing ``None`` as *authorizer_callback* will disable the authorizer.
893
894      .. versionchanged:: 3.11
895         Added support for disabling the authorizer using ``None``.
896
897
898   .. method:: set_progress_handler(progress_handler, n)
899
900      Register callable *progress_handler* to be invoked for every *n*
901      instructions of the SQLite virtual machine. This is useful if you want to
902      get called from SQLite during long-running operations, for example to update
903      a GUI.
904
905      If you want to clear any previously installed progress handler, call the
906      method with ``None`` for *progress_handler*.
907
908      Returning a non-zero value from the handler function will terminate the
909      currently executing query and cause it to raise an :exc:`OperationalError`
910      exception.
911
912
913   .. method:: set_trace_callback(trace_callback)
914
915      Register callable *trace_callback* to be invoked for each SQL statement
916      that is actually executed by the SQLite backend.
917
918      The only argument passed to the callback is the statement (as
919      :class:`str`) that is being executed. The return value of the callback is
920      ignored. Note that the backend does not only run statements passed to the
921      :meth:`Cursor.execute` methods.  Other sources include the
922      :ref:`transaction management <sqlite3-controlling-transactions>` of the
923      :mod:`!sqlite3` module and the execution of triggers defined in the current
924      database.
925
926      Passing ``None`` as *trace_callback* will disable the trace callback.
927
928      .. note::
929         Exceptions raised in the trace callback are not propagated. As a
930         development and debugging aid, use
931         :meth:`~sqlite3.enable_callback_tracebacks` to enable printing
932         tracebacks from exceptions raised in the trace callback.
933
934      .. versionadded:: 3.3
935
936
937   .. method:: enable_load_extension(enabled, /)
938
939      Enable the SQLite engine to load SQLite extensions from shared libraries
940      if *enabled* is ``True``;
941      else, disallow loading SQLite extensions.
942      SQLite extensions can define new functions,
943      aggregates or whole new virtual table implementations.  One well-known
944      extension is the fulltext-search extension distributed with SQLite.
945
946      .. note::
947
948         The :mod:`!sqlite3` module is not built with loadable extension support by
949         default, because some platforms (notably macOS) have SQLite
950         libraries which are compiled without this feature.
951         To get loadable extension support,
952         you must pass the :option:`--enable-loadable-sqlite-extensions` option
953         to :program:`configure`.
954
955      .. audit-event:: sqlite3.enable_load_extension connection,enabled sqlite3.Connection.enable_load_extension
956
957      .. versionadded:: 3.2
958
959      .. versionchanged:: 3.10
960         Added the ``sqlite3.enable_load_extension`` auditing event.
961
962      .. testsetup:: sqlite3.loadext
963
964         import sqlite3
965         con = sqlite3.connect(":memory:")
966
967      .. testcode:: sqlite3.loadext
968         :skipif: True  # not testable at the moment
969
970         con.enable_load_extension(True)
971
972         # Load the fulltext search extension
973         con.execute("select load_extension('./fts3.so')")
974
975         # alternatively you can load the extension using an API call:
976         # con.load_extension("./fts3.so")
977
978         # disable extension loading again
979         con.enable_load_extension(False)
980
981         # example from SQLite wiki
982         con.execute("CREATE VIRTUAL TABLE recipe USING fts3(name, ingredients)")
983         con.executescript("""
984             INSERT INTO recipe (name, ingredients) VALUES('broccoli stew', 'broccoli peppers cheese tomatoes');
985             INSERT INTO recipe (name, ingredients) VALUES('pumpkin stew', 'pumpkin onions garlic celery');
986             INSERT INTO recipe (name, ingredients) VALUES('broccoli pie', 'broccoli cheese onions flour');
987             INSERT INTO recipe (name, ingredients) VALUES('pumpkin pie', 'pumpkin sugar flour butter');
988             """)
989         for row in con.execute("SELECT rowid, name, ingredients FROM recipe WHERE name MATCH 'pie'"):
990             print(row)
991
992         con.close()
993
994      .. testoutput:: sqlite3.loadext
995         :hide:
996
997         (2, 'broccoli pie', 'broccoli cheese onions flour')
998         (3, 'pumpkin pie', 'pumpkin sugar flour butter')
999
1000   .. method:: load_extension(path, /)
1001
1002      Load an SQLite extension from a shared library located at *path*.
1003      Enable extension loading with :meth:`enable_load_extension` before
1004      calling this method.
1005
1006      .. audit-event:: sqlite3.load_extension connection,path sqlite3.Connection.load_extension
1007
1008      .. versionadded:: 3.2
1009
1010      .. versionchanged:: 3.10
1011         Added the ``sqlite3.load_extension`` auditing event.
1012
1013   .. method:: iterdump
1014
1015      Return an :term:`iterator` to dump the database as SQL source code.
1016      Useful when saving an in-memory database for later restoration.
1017      Similar to the ``.dump`` command in the :program:`sqlite3` shell.
1018
1019      Example:
1020
1021      .. testcode::
1022
1023         # Convert file example.db to SQL dump file dump.sql
1024         con = sqlite3.connect('example.db')
1025         with open('dump.sql', 'w') as f:
1026             for line in con.iterdump():
1027                 f.write('%s\n' % line)
1028         con.close()
1029
1030
1031   .. method:: backup(target, *, pages=-1, progress=None, name="main", sleep=0.250)
1032
1033      Create a backup of an SQLite database.
1034
1035      Works even if the database is being accessed by other clients
1036      or concurrently by the same connection.
1037
1038      :param ~sqlite3.Connection target:
1039          The database connection to save the backup to.
1040
1041      :param int pages:
1042          The number of pages to copy at a time.
1043          If equal to or less than ``0``,
1044          the entire database is copied in a single step.
1045          Defaults to ``-1``.
1046
1047      :param progress:
1048          If set to a callable, it is invoked with three integer arguments for
1049          every backup iteration:
1050          the *status* of the last iteration,
1051          the *remaining* number of pages still to be copied,
1052          and the *total* number of pages.
1053          Defaults to ``None``.
1054      :type progress: :term:`callback` | None
1055
1056      :param str name:
1057          The name of the database to back up.
1058          Either ``"main"`` (the default) for the main database,
1059          ``"temp"`` for the temporary database,
1060          or the name of a custom database as attached using the
1061          ``ATTACH DATABASE`` SQL statement.
1062
1063      :param float sleep:
1064          The number of seconds to sleep between successive attempts
1065          to back up remaining pages.
1066
1067      Example 1, copy an existing database into another:
1068
1069      .. testcode::
1070
1071         def progress(status, remaining, total):
1072             print(f'Copied {total-remaining} of {total} pages...')
1073
1074         src = sqlite3.connect('example.db')
1075         dst = sqlite3.connect('backup.db')
1076         with dst:
1077             src.backup(dst, pages=1, progress=progress)
1078         dst.close()
1079         src.close()
1080
1081      .. testoutput::
1082         :hide:
1083
1084         Copied 0 of 0 pages...
1085
1086      Example 2, copy an existing database into a transient copy:
1087
1088      .. testcode::
1089
1090         src = sqlite3.connect('example.db')
1091         dst = sqlite3.connect(':memory:')
1092         src.backup(dst)
1093
1094      .. versionadded:: 3.7
1095
1096   .. method:: getlimit(category, /)
1097
1098      Get a connection runtime limit.
1099
1100      :param int category:
1101         The `SQLite limit category`_ to be queried.
1102
1103      :rtype: int
1104
1105      :raises ProgrammingError:
1106         If *category* is not recognised by the underlying SQLite library.
1107
1108      Example, query the maximum length of an SQL statement
1109      for :class:`Connection` ``con`` (the default is 1000000000):
1110
1111      .. testsetup:: sqlite3.limits
1112
1113         import sqlite3
1114         con = sqlite3.connect(":memory:")
1115         con.setlimit(sqlite3.SQLITE_LIMIT_SQL_LENGTH, 1_000_000_000)
1116         con.setlimit(sqlite3.SQLITE_LIMIT_ATTACHED, 10)
1117
1118      .. doctest:: sqlite3.limits
1119
1120         >>> con.getlimit(sqlite3.SQLITE_LIMIT_SQL_LENGTH)
1121         1000000000
1122
1123      .. versionadded:: 3.11
1124
1125
1126   .. method:: setlimit(category, limit, /)
1127
1128      Set a connection runtime limit.
1129      Attempts to increase a limit above its hard upper bound are silently
1130      truncated to the hard upper bound. Regardless of whether or not the limit
1131      was changed, the prior value of the limit is returned.
1132
1133      :param int category:
1134         The `SQLite limit category`_ to be set.
1135
1136      :param int limit:
1137         The value of the new limit.
1138         If negative, the current limit is unchanged.
1139
1140      :rtype: int
1141
1142      :raises ProgrammingError:
1143         If *category* is not recognised by the underlying SQLite library.
1144
1145      Example, limit the number of attached databases to 1
1146      for :class:`Connection` ``con`` (the default limit is 10):
1147
1148      .. doctest:: sqlite3.limits
1149
1150         >>> con.setlimit(sqlite3.SQLITE_LIMIT_ATTACHED, 1)
1151         10
1152         >>> con.getlimit(sqlite3.SQLITE_LIMIT_ATTACHED)
1153         1
1154
1155      .. versionadded:: 3.11
1156
1157   .. _SQLite limit category: https://www.sqlite.org/c3ref/c_limit_attached.html
1158
1159
1160   .. method:: serialize(*, name="main")
1161
1162      Serialize a database into a :class:`bytes` object.  For an
1163      ordinary on-disk database file, the serialization is just a copy of the
1164      disk file.  For an in-memory database or a "temp" database, the
1165      serialization is the same sequence of bytes which would be written to
1166      disk if that database were backed up to disk.
1167
1168      :param str name:
1169         The database name to be serialized.
1170         Defaults to ``"main"``.
1171
1172      :rtype: bytes
1173
1174      .. note::
1175
1176         This method is only available if the underlying SQLite library has the
1177         serialize API.
1178
1179      .. versionadded:: 3.11
1180
1181
1182   .. method:: deserialize(data, /, *, name="main")
1183
1184      Deserialize a :meth:`serialized <serialize>` database into a
1185      :class:`Connection`.
1186      This method causes the database connection to disconnect from database
1187      *name*, and reopen *name* as an in-memory database based on the
1188      serialization contained in *data*.
1189
1190      :param bytes data:
1191         A serialized database.
1192
1193      :param str name:
1194         The database name to deserialize into.
1195         Defaults to ``"main"``.
1196
1197      :raises OperationalError:
1198         If the database connection is currently involved in a read
1199         transaction or a backup operation.
1200
1201      :raises DatabaseError:
1202         If *data* does not contain a valid SQLite database.
1203
1204      :raises OverflowError:
1205         If :func:`len(data) <len>` is larger than ``2**63 - 1``.
1206
1207      .. note::
1208
1209         This method is only available if the underlying SQLite library has the
1210         deserialize API.
1211
1212      .. versionadded:: 3.11
1213
1214   .. attribute:: in_transaction
1215
1216      This read-only attribute corresponds to the low-level SQLite
1217      `autocommit mode`_.
1218
1219      ``True`` if a transaction is active (there are uncommitted changes),
1220      ``False`` otherwise.
1221
1222      .. versionadded:: 3.2
1223
1224   .. attribute:: isolation_level
1225
1226      This attribute controls the :ref:`transaction handling
1227      <sqlite3-controlling-transactions>` performed by :mod:`!sqlite3`.
1228      If set to ``None``, transactions are never implicitly opened.
1229      If set to one of ``"DEFERRED"``, ``"IMMEDIATE"``, or ``"EXCLUSIVE"``,
1230      corresponding to the underlying `SQLite transaction behaviour`_,
1231      implicit :ref:`transaction management
1232      <sqlite3-controlling-transactions>` is performed.
1233
1234      If not overridden by the *isolation_level* parameter of :func:`connect`,
1235      the default is ``""``, which is an alias for ``"DEFERRED"``.
1236
1237   .. attribute:: row_factory
1238
1239      The initial :attr:`~Cursor.row_factory`
1240      for :class:`Cursor` objects created from this connection.
1241      Assigning to this attribute does not affect the :attr:`!row_factory`
1242      of existing cursors belonging to this connection, only new ones.
1243      Is ``None`` by default,
1244      meaning each row is returned as a :class:`tuple`.
1245
1246      See :ref:`sqlite3-howto-row-factory` for more details.
1247
1248   .. attribute:: text_factory
1249
1250      A callable that accepts a :class:`bytes` parameter and returns a text
1251      representation of it.
1252      The callable is invoked for SQLite values with the ``TEXT`` data type.
1253      By default, this attribute is set to :class:`str`.
1254      If you want to return ``bytes`` instead, set *text_factory* to ``bytes``.
1255
1256      Example:
1257
1258      .. testcode::
1259
1260         con = sqlite3.connect(":memory:")
1261         cur = con.cursor()
1262
1263         AUSTRIA = "Österreich"
1264
1265         # by default, rows are returned as str
1266         cur.execute("SELECT ?", (AUSTRIA,))
1267         row = cur.fetchone()
1268         assert row[0] == AUSTRIA
1269
1270         # but we can make sqlite3 always return bytestrings ...
1271         con.text_factory = bytes
1272         cur.execute("SELECT ?", (AUSTRIA,))
1273         row = cur.fetchone()
1274         assert type(row[0]) is bytes
1275         # the bytestrings will be encoded in UTF-8, unless you stored garbage in the
1276         # database ...
1277         assert row[0] == AUSTRIA.encode("utf-8")
1278
1279         # we can also implement a custom text_factory ...
1280         # here we implement one that appends "foo" to all strings
1281         con.text_factory = lambda x: x.decode("utf-8") + "foo"
1282         cur.execute("SELECT ?", ("bar",))
1283         row = cur.fetchone()
1284         assert row[0] == "barfoo"
1285
1286         con.close()
1287
1288   .. attribute:: total_changes
1289
1290      Return the total number of database rows that have been modified, inserted, or
1291      deleted since the database connection was opened.
1292
1293
1294.. _sqlite3-cursor-objects:
1295
1296Cursor objects
1297^^^^^^^^^^^^^^
1298
1299   A ``Cursor`` object represents a `database cursor`_
1300   which is used to execute SQL statements,
1301   and manage the context of a fetch operation.
1302   Cursors are created using :meth:`Connection.cursor`,
1303   or by using any of the :ref:`connection shortcut methods
1304   <sqlite3-connection-shortcuts>`.
1305
1306   Cursor objects are :term:`iterators <iterator>`,
1307   meaning that if you :meth:`~Cursor.execute` a ``SELECT`` query,
1308   you can simply iterate over the cursor to fetch the resulting rows:
1309
1310   .. testsetup:: sqlite3.cursor
1311
1312      import sqlite3
1313      con = sqlite3.connect(":memory:", isolation_level=None)
1314      cur = con.execute("CREATE TABLE data(t)")
1315      cur.execute("INSERT INTO data VALUES(1)")
1316
1317   .. testcode:: sqlite3.cursor
1318
1319      for row in cur.execute("SELECT t FROM data"):
1320          print(row)
1321
1322   .. testoutput:: sqlite3.cursor
1323      :hide:
1324
1325      (1,)
1326
1327   .. _database cursor: https://en.wikipedia.org/wiki/Cursor_(databases)
1328
1329.. class:: Cursor
1330
1331   A :class:`Cursor` instance has the following attributes and methods.
1332
1333   .. index:: single: ? (question mark); in SQL statements
1334   .. index:: single: : (colon); in SQL statements
1335
1336   .. method:: execute(sql, parameters=(), /)
1337
1338      Execute SQL a single SQL statement,
1339      optionally binding Python values using
1340      :ref:`placeholders <sqlite3-placeholders>`.
1341
1342      :param str sql:
1343         A single SQL statement.
1344
1345      :param parameters:
1346         Python values to bind to placeholders in *sql*.
1347         A :class:`!dict` if named placeholders are used.
1348         A :term:`!sequence` if unnamed placeholders are used.
1349         See :ref:`sqlite3-placeholders`.
1350      :type parameters: :class:`dict` | :term:`sequence`
1351
1352      :raises ProgrammingError:
1353         If *sql* contains more than one SQL statement.
1354
1355      If :attr:`~Connection.isolation_level` is not ``None``,
1356      *sql* is an ``INSERT``, ``UPDATE``, ``DELETE``, or ``REPLACE`` statement,
1357      and there is no open transaction,
1358      a transaction is implicitly opened before executing *sql*.
1359
1360      Use :meth:`executescript` to execute multiple SQL statements.
1361
1362   .. method:: executemany(sql, parameters, /)
1363
1364      For every item in *parameters*,
1365      repeatedly execute the :ref:`parameterized <sqlite3-placeholders>`
1366      :abbr:`DML (Data Manipulation Language)` SQL statement *sql*.
1367
1368      Uses the same implicit transaction handling as :meth:`~Cursor.execute`.
1369
1370      :param str sql:
1371         A single SQL DML statement.
1372
1373      :param parameters:
1374         An :term:`!iterable` of parameters to bind with
1375         the placeholders in *sql*.
1376         See :ref:`sqlite3-placeholders`.
1377      :type parameters: :term:`iterable`
1378
1379      :raises ProgrammingError:
1380         If *sql* contains more than one SQL statement,
1381         or is not a DML statment.
1382
1383      Example:
1384
1385      .. testcode:: sqlite3.cursor
1386
1387         rows = [
1388             ("row1",),
1389             ("row2",),
1390         ]
1391         # cur is an sqlite3.Cursor object
1392         cur.executemany("INSERT INTO data VALUES(?)", rows)
1393
1394      .. note::
1395
1396         Any resulting rows are discarded,
1397         including DML statements with `RETURNING clauses`_.
1398
1399      .. _RETURNING clauses: https://www.sqlite.org/lang_returning.html
1400
1401   .. method:: executescript(sql_script, /)
1402
1403      Execute the SQL statements in *sql_script*.
1404      If there is a pending transaction,
1405      an implicit ``COMMIT`` statement is executed first.
1406      No other implicit transaction control is performed;
1407      any transaction control must be added to *sql_script*.
1408
1409      *sql_script* must be a :class:`string <str>`.
1410
1411      Example:
1412
1413      .. testcode:: sqlite3.cursor
1414
1415         # cur is an sqlite3.Cursor object
1416         cur.executescript("""
1417             BEGIN;
1418             CREATE TABLE person(firstname, lastname, age);
1419             CREATE TABLE book(title, author, published);
1420             CREATE TABLE publisher(name, address);
1421             COMMIT;
1422         """)
1423
1424
1425   .. method:: fetchone()
1426
1427      If :attr:`~Cursor.row_factory` is ``None``,
1428      return the next row query result set as a :class:`tuple`.
1429      Else, pass it to the row factory and return its result.
1430      Return ``None`` if no more data is available.
1431
1432
1433   .. method:: fetchmany(size=cursor.arraysize)
1434
1435      Return the next set of rows of a query result as a :class:`list`.
1436      Return an empty list if no more rows are available.
1437
1438      The number of rows to fetch per call is specified by the *size* parameter.
1439      If *size* is not given, :attr:`arraysize` determines the number of rows
1440      to be fetched.
1441      If fewer than *size* rows are available,
1442      as many rows as are available are returned.
1443
1444      Note there are performance considerations involved with the *size* parameter.
1445      For optimal performance, it is usually best to use the arraysize attribute.
1446      If the *size* parameter is used, then it is best for it to retain the same
1447      value from one :meth:`fetchmany` call to the next.
1448
1449   .. method:: fetchall()
1450
1451      Return all (remaining) rows of a query result as a :class:`list`.
1452      Return an empty list if no rows are available.
1453      Note that the :attr:`arraysize` attribute can affect the performance of
1454      this operation.
1455
1456   .. method:: close()
1457
1458      Close the cursor now (rather than whenever ``__del__`` is called).
1459
1460      The cursor will be unusable from this point forward; a :exc:`ProgrammingError`
1461      exception will be raised if any operation is attempted with the cursor.
1462
1463   .. method:: setinputsizes(sizes, /)
1464
1465      Required by the DB-API. Does nothing in :mod:`!sqlite3`.
1466
1467   .. method:: setoutputsize(size, column=None, /)
1468
1469      Required by the DB-API. Does nothing in :mod:`!sqlite3`.
1470
1471   .. attribute:: arraysize
1472
1473      Read/write attribute that controls the number of rows returned by :meth:`fetchmany`.
1474      The default value is 1 which means a single row would be fetched per call.
1475
1476   .. attribute:: connection
1477
1478      Read-only attribute that provides the SQLite database :class:`Connection`
1479      belonging to the cursor.  A :class:`Cursor` object created by
1480      calling :meth:`con.cursor() <Connection.cursor>` will have a
1481      :attr:`connection` attribute that refers to *con*:
1482
1483      .. doctest::
1484
1485         >>> con = sqlite3.connect(":memory:")
1486         >>> cur = con.cursor()
1487         >>> cur.connection == con
1488         True
1489
1490   .. attribute:: description
1491
1492      Read-only attribute that provides the column names of the last query. To
1493      remain compatible with the Python DB API, it returns a 7-tuple for each
1494      column where the last six items of each tuple are ``None``.
1495
1496      It is set for ``SELECT`` statements without any matching rows as well.
1497
1498   .. attribute:: lastrowid
1499
1500      Read-only attribute that provides the row id of the last inserted row. It
1501      is only updated after successful ``INSERT`` or ``REPLACE`` statements
1502      using the :meth:`execute` method.  For other statements, after
1503      :meth:`executemany` or :meth:`executescript`, or if the insertion failed,
1504      the value of ``lastrowid`` is left unchanged.  The initial value of
1505      ``lastrowid`` is ``None``.
1506
1507      .. note::
1508         Inserts into ``WITHOUT ROWID`` tables are not recorded.
1509
1510      .. versionchanged:: 3.6
1511         Added support for the ``REPLACE`` statement.
1512
1513   .. attribute:: rowcount
1514
1515      Read-only attribute that provides the number of modified rows for
1516      ``INSERT``, ``UPDATE``, ``DELETE``, and ``REPLACE`` statements;
1517      is ``-1`` for other statements,
1518      including :abbr:`CTE (Common Table Expression)` queries.
1519      It is only updated by the :meth:`execute` and :meth:`executemany` methods,
1520      after the statement has run to completion.
1521      This means that any resulting rows must be fetched in order for
1522      :attr:`!rowcount` to be updated.
1523
1524   .. attribute:: row_factory
1525
1526      Control how a row fetched from this :class:`!Cursor` is represented.
1527      If ``None``, a row is represented as a :class:`tuple`.
1528      Can be set to the included :class:`sqlite3.Row`;
1529      or a :term:`callable` that accepts two arguments,
1530      a :class:`Cursor` object and the :class:`!tuple` of row values,
1531      and returns a custom object representing an SQLite row.
1532
1533      Defaults to what :attr:`Connection.row_factory` was set to
1534      when the :class:`!Cursor` was created.
1535      Assigning to this attribute does not affect
1536      :attr:`Connection.row_factory` of the parent connection.
1537
1538      See :ref:`sqlite3-howto-row-factory` for more details.
1539
1540
1541.. The sqlite3.Row example used to be a how-to. It has now been incorporated
1542   into the Row reference. We keep the anchor here in order not to break
1543   existing links.
1544
1545.. _sqlite3-columns-by-name:
1546.. _sqlite3-row-objects:
1547
1548Row objects
1549^^^^^^^^^^^
1550
1551.. class:: Row
1552
1553   A :class:`!Row` instance serves as a highly optimized
1554   :attr:`~Connection.row_factory` for :class:`Connection` objects.
1555   It supports iteration, equality testing, :func:`len`,
1556   and :term:`mapping` access by column name and index.
1557
1558   Two :class:`!Row` objects compare equal
1559   if they have identical column names and values.
1560
1561   See :ref:`sqlite3-howto-row-factory` for more details.
1562
1563   .. method:: keys
1564
1565      Return a :class:`list` of column names as :class:`strings <str>`.
1566      Immediately after a query,
1567      it is the first member of each tuple in :attr:`Cursor.description`.
1568
1569   .. versionchanged:: 3.5
1570      Added support of slicing.
1571
1572
1573.. _sqlite3-blob-objects:
1574
1575Blob objects
1576^^^^^^^^^^^^
1577
1578.. versionadded:: 3.11
1579
1580.. class:: Blob
1581
1582   A :class:`Blob` instance is a :term:`file-like object`
1583   that can read and write data in an SQLite :abbr:`BLOB (Binary Large OBject)`.
1584   Call :func:`len(blob) <len>` to get the size (number of bytes) of the blob.
1585   Use indices and :term:`slices <slice>` for direct access to the blob data.
1586
1587   Use the :class:`Blob` as a :term:`context manager` to ensure that the blob
1588   handle is closed after use.
1589
1590   .. testcode::
1591
1592      con = sqlite3.connect(":memory:")
1593      con.execute("CREATE TABLE test(blob_col blob)")
1594      con.execute("INSERT INTO test(blob_col) VALUES(zeroblob(13))")
1595
1596      # Write to our blob, using two write operations:
1597      with con.blobopen("test", "blob_col", 1) as blob:
1598          blob.write(b"hello, ")
1599          blob.write(b"world.")
1600          # Modify the first and last bytes of our blob
1601          blob[0] = ord("H")
1602          blob[-1] = ord("!")
1603
1604      # Read the contents of our blob
1605      with con.blobopen("test", "blob_col", 1) as blob:
1606          greeting = blob.read()
1607
1608      print(greeting)  # outputs "b'Hello, world!'"
1609
1610   .. testoutput::
1611      :hide:
1612
1613      b'Hello, world!'
1614
1615   .. method:: close()
1616
1617      Close the blob.
1618
1619      The blob will be unusable from this point onward.  An
1620      :class:`~sqlite3.Error` (or subclass) exception will be raised if any
1621      further operation is attempted with the blob.
1622
1623   .. method:: read(length=-1, /)
1624
1625      Read *length* bytes of data from the blob at the current offset position.
1626      If the end of the blob is reached, the data up to
1627      :abbr:`EOF (End of File)` will be returned.  When *length* is not
1628      specified, or is negative, :meth:`~Blob.read` will read until the end of
1629      the blob.
1630
1631   .. method:: write(data, /)
1632
1633      Write *data* to the blob at the current offset.  This function cannot
1634      change the blob length.  Writing beyond the end of the blob will raise
1635      :exc:`ValueError`.
1636
1637   .. method:: tell()
1638
1639      Return the current access position of the blob.
1640
1641   .. method:: seek(offset, origin=os.SEEK_SET, /)
1642
1643      Set the current access position of the blob to *offset*.  The *origin*
1644      argument defaults to :data:`os.SEEK_SET` (absolute blob positioning).
1645      Other values for *origin* are :data:`os.SEEK_CUR` (seek relative to the
1646      current position) and :data:`os.SEEK_END` (seek relative to the blob’s
1647      end).
1648
1649
1650PrepareProtocol objects
1651^^^^^^^^^^^^^^^^^^^^^^^
1652
1653.. class:: PrepareProtocol
1654
1655   The PrepareProtocol type's single purpose is to act as a :pep:`246` style
1656   adaption protocol for objects that can :ref:`adapt themselves
1657   <sqlite3-conform>` to :ref:`native SQLite types <sqlite3-types>`.
1658
1659
1660.. _sqlite3-exceptions:
1661
1662Exceptions
1663^^^^^^^^^^
1664
1665The exception hierarchy is defined by the DB-API 2.0 (:pep:`249`).
1666
1667.. exception:: Warning
1668
1669   This exception is not currently raised by the :mod:`!sqlite3` module,
1670   but may be raised by applications using :mod:`!sqlite3`,
1671   for example if a user-defined function truncates data while inserting.
1672   ``Warning`` is a subclass of :exc:`Exception`.
1673
1674.. exception:: Error
1675
1676   The base class of the other exceptions in this module.
1677   Use this to catch all errors with one single :keyword:`except` statement.
1678   ``Error`` is a subclass of :exc:`Exception`.
1679
1680   If the exception originated from within the SQLite library,
1681   the following two attributes are added to the exception:
1682
1683   .. attribute:: sqlite_errorcode
1684
1685      The numeric error code from the
1686      `SQLite API <https://sqlite.org/rescode.html>`_
1687
1688      .. versionadded:: 3.11
1689
1690   .. attribute:: sqlite_errorname
1691
1692      The symbolic name of the numeric error code
1693      from the `SQLite API <https://sqlite.org/rescode.html>`_
1694
1695      .. versionadded:: 3.11
1696
1697.. exception:: InterfaceError
1698
1699   Exception raised for misuse of the low-level SQLite C API.
1700   In other words, if this exception is raised, it probably indicates a bug in the
1701   :mod:`!sqlite3` module.
1702   ``InterfaceError`` is a subclass of :exc:`Error`.
1703
1704.. exception:: DatabaseError
1705
1706   Exception raised for errors that are related to the database.
1707   This serves as the base exception for several types of database errors.
1708   It is only raised implicitly through the specialised subclasses.
1709   ``DatabaseError`` is a subclass of :exc:`Error`.
1710
1711.. exception:: DataError
1712
1713   Exception raised for errors caused by problems with the processed data,
1714   like numeric values out of range, and strings which are too long.
1715   ``DataError`` is a subclass of :exc:`DatabaseError`.
1716
1717.. exception:: OperationalError
1718
1719   Exception raised for errors that are related to the database's operation,
1720   and not necessarily under the control of the programmer.
1721   For example, the database path is not found,
1722   or a transaction could not be processed.
1723   ``OperationalError`` is a subclass of :exc:`DatabaseError`.
1724
1725.. exception:: IntegrityError
1726
1727   Exception raised when the relational integrity of the database is affected,
1728   e.g. a foreign key check fails.  It is a subclass of :exc:`DatabaseError`.
1729
1730.. exception:: InternalError
1731
1732   Exception raised when SQLite encounters an internal error.
1733   If this is raised, it may indicate that there is a problem with the runtime
1734   SQLite library.
1735   ``InternalError`` is a subclass of :exc:`DatabaseError`.
1736
1737.. exception:: ProgrammingError
1738
1739   Exception raised for :mod:`!sqlite3` API programming errors,
1740   for example supplying the wrong number of bindings to a query,
1741   or trying to operate on a closed :class:`Connection`.
1742   ``ProgrammingError`` is a subclass of :exc:`DatabaseError`.
1743
1744.. exception:: NotSupportedError
1745
1746   Exception raised in case a method or database API is not supported by the
1747   underlying SQLite library. For example, setting *deterministic* to
1748   ``True`` in :meth:`~Connection.create_function`, if the underlying SQLite library
1749   does not support deterministic functions.
1750   ``NotSupportedError`` is a subclass of :exc:`DatabaseError`.
1751
1752
1753.. _sqlite3-types:
1754
1755SQLite and Python types
1756^^^^^^^^^^^^^^^^^^^^^^^
1757
1758SQLite natively supports the following types: ``NULL``, ``INTEGER``,
1759``REAL``, ``TEXT``, ``BLOB``.
1760
1761The following Python types can thus be sent to SQLite without any problem:
1762
1763+-------------------------------+-------------+
1764| Python type                   | SQLite type |
1765+===============================+=============+
1766| ``None``                      | ``NULL``    |
1767+-------------------------------+-------------+
1768| :class:`int`                  | ``INTEGER`` |
1769+-------------------------------+-------------+
1770| :class:`float`                | ``REAL``    |
1771+-------------------------------+-------------+
1772| :class:`str`                  | ``TEXT``    |
1773+-------------------------------+-------------+
1774| :class:`bytes`                | ``BLOB``    |
1775+-------------------------------+-------------+
1776
1777
1778This is how SQLite types are converted to Python types by default:
1779
1780+-------------+----------------------------------------------+
1781| SQLite type | Python type                                  |
1782+=============+==============================================+
1783| ``NULL``    | ``None``                                     |
1784+-------------+----------------------------------------------+
1785| ``INTEGER`` | :class:`int`                                 |
1786+-------------+----------------------------------------------+
1787| ``REAL``    | :class:`float`                               |
1788+-------------+----------------------------------------------+
1789| ``TEXT``    | depends on :attr:`~Connection.text_factory`, |
1790|             | :class:`str` by default                      |
1791+-------------+----------------------------------------------+
1792| ``BLOB``    | :class:`bytes`                               |
1793+-------------+----------------------------------------------+
1794
1795The type system of the :mod:`!sqlite3` module is extensible in two ways: you can
1796store additional Python types in an SQLite database via
1797:ref:`object adapters <sqlite3-adapters>`,
1798and you can let the :mod:`!sqlite3` module convert SQLite types to
1799Python types via :ref:`converters <sqlite3-converters>`.
1800
1801
1802.. _sqlite3-default-converters:
1803
1804Default adapters and converters
1805^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1806
1807There are default adapters for the date and datetime types in the datetime
1808module. They will be sent as ISO dates/ISO timestamps to SQLite.
1809
1810The default converters are registered under the name "date" for
1811:class:`datetime.date` and under the name "timestamp" for
1812:class:`datetime.datetime`.
1813
1814This way, you can use date/timestamps from Python without any additional
1815fiddling in most cases. The format of the adapters is also compatible with the
1816experimental SQLite date/time functions.
1817
1818The following example demonstrates this.
1819
1820.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py
1821
1822If a timestamp stored in SQLite has a fractional part longer than 6
1823numbers, its value will be truncated to microsecond precision by the
1824timestamp converter.
1825
1826.. note::
1827
1828   The default "timestamp" converter ignores UTC offsets in the database and
1829   always returns a naive :class:`datetime.datetime` object. To preserve UTC
1830   offsets in timestamps, either leave converters disabled, or register an
1831   offset-aware converter with :func:`register_converter`.
1832
1833
1834.. _sqlite3-howtos:
1835
1836How-to guides
1837-------------
1838
1839.. _sqlite3-placeholders:
1840
1841How to use placeholders to bind values in SQL queries
1842^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1843
1844SQL operations usually need to use values from Python variables. However,
1845beware of using Python's string operations to assemble queries, as they
1846are vulnerable to `SQL injection attacks`_. For example, an attacker can simply
1847close the single quote and inject ``OR TRUE`` to select all rows::
1848
1849   >>> # Never do this -- insecure!
1850   >>> symbol = input()
1851   ' OR TRUE; --
1852   >>> sql = "SELECT * FROM stocks WHERE symbol = '%s'" % symbol
1853   >>> print(sql)
1854   SELECT * FROM stocks WHERE symbol = '' OR TRUE; --'
1855   >>> cur.execute(sql)
1856
1857Instead, use the DB-API's parameter substitution. To insert a variable into a
1858query string, use a placeholder in the string, and substitute the actual values
1859into the query by providing them as a :class:`tuple` of values to the second
1860argument of the cursor's :meth:`~Cursor.execute` method.
1861
1862An SQL statement may use one of two kinds of placeholders:
1863question marks (qmark style) or named placeholders (named style).
1864For the qmark style, *parameters* must be a
1865:term:`sequence` whose length must match the number of placeholders,
1866or a :exc:`ProgrammingError` is raised.
1867For the named style, *parameters* should be
1868an instance of a :class:`dict` (or a subclass),
1869which must contain keys for all named parameters;
1870any extra items are ignored.
1871Here's an example of both styles:
1872
1873.. testcode::
1874
1875   con = sqlite3.connect(":memory:")
1876   cur = con.execute("CREATE TABLE lang(name, first_appeared)")
1877
1878   # This is the named style used with executemany():
1879   data = (
1880       {"name": "C", "year": 1972},
1881       {"name": "Fortran", "year": 1957},
1882       {"name": "Python", "year": 1991},
1883       {"name": "Go", "year": 2009},
1884   )
1885   cur.executemany("INSERT INTO lang VALUES(:name, :year)", data)
1886
1887   # This is the qmark style used in a SELECT query:
1888   params = (1972,)
1889   cur.execute("SELECT * FROM lang WHERE first_appeared = ?", params)
1890   print(cur.fetchall())
1891
1892.. testoutput::
1893   :hide:
1894
1895   [('C', 1972)]
1896
1897.. note::
1898
1899   :pep:`249` numeric placeholders are *not* supported.
1900   If used, they will be interpreted as named placeholders.
1901
1902
1903.. _sqlite3-adapters:
1904
1905How to adapt custom Python types to SQLite values
1906^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1907
1908SQLite supports only a limited set of data types natively.
1909To store custom Python types in SQLite databases, *adapt* them to one of the
1910:ref:`Python types SQLite natively understands <sqlite3-types>`.
1911
1912There are two ways to adapt Python objects to SQLite types:
1913letting your object adapt itself, or using an *adapter callable*.
1914The latter will take precedence above the former.
1915For a library that exports a custom type,
1916it may make sense to enable that type to adapt itself.
1917As an application developer, it may make more sense to take direct control by
1918registering custom adapter functions.
1919
1920
1921.. _sqlite3-conform:
1922
1923How to write adaptable objects
1924""""""""""""""""""""""""""""""
1925
1926Suppose we have a :class:`!Point` class that represents a pair of coordinates,
1927``x`` and ``y``, in a Cartesian coordinate system.
1928The coordinate pair will be stored as a text string in the database,
1929using a semicolon to separate the coordinates.
1930This can be implemented by adding a ``__conform__(self, protocol)``
1931method which returns the adapted value.
1932The object passed to *protocol* will be of type :class:`PrepareProtocol`.
1933
1934.. testcode::
1935
1936   class Point:
1937       def __init__(self, x, y):
1938           self.x, self.y = x, y
1939
1940       def __conform__(self, protocol):
1941           if protocol is sqlite3.PrepareProtocol:
1942               return f"{self.x};{self.y}"
1943
1944   con = sqlite3.connect(":memory:")
1945   cur = con.cursor()
1946
1947   cur.execute("SELECT ?", (Point(4.0, -3.2),))
1948   print(cur.fetchone()[0])
1949
1950.. testoutput::
1951   :hide:
1952
1953   4.0;-3.2
1954
1955
1956How to register adapter callables
1957"""""""""""""""""""""""""""""""""
1958
1959The other possibility is to create a function that converts the Python object
1960to an SQLite-compatible type.
1961This function can then be registered using :func:`register_adapter`.
1962
1963.. testcode::
1964
1965   class Point:
1966       def __init__(self, x, y):
1967           self.x, self.y = x, y
1968
1969   def adapt_point(point):
1970       return f"{point.x};{point.y}"
1971
1972   sqlite3.register_adapter(Point, adapt_point)
1973
1974   con = sqlite3.connect(":memory:")
1975   cur = con.cursor()
1976
1977   cur.execute("SELECT ?", (Point(1.0, 2.5),))
1978   print(cur.fetchone()[0])
1979
1980.. testoutput::
1981   :hide:
1982
1983   1.0;2.5
1984
1985
1986.. _sqlite3-converters:
1987
1988How to convert SQLite values to custom Python types
1989^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1990
1991Writing an adapter lets you convert *from* custom Python types *to* SQLite
1992values.
1993To be able to convert *from* SQLite values *to* custom Python types,
1994we use *converters*.
1995
1996Let's go back to the :class:`!Point` class. We stored the x and y coordinates
1997separated via semicolons as strings in SQLite.
1998
1999First, we'll define a converter function that accepts the string as a parameter
2000and constructs a :class:`!Point` object from it.
2001
2002.. note::
2003
2004   Converter functions are **always** passed a :class:`bytes` object,
2005   no matter the underlying SQLite data type.
2006
2007.. testcode::
2008
2009   def convert_point(s):
2010       x, y = map(float, s.split(b";"))
2011       return Point(x, y)
2012
2013We now need to tell :mod:`!sqlite3` when it should convert a given SQLite value.
2014This is done when connecting to a database, using the *detect_types* parameter
2015of :func:`connect`. There are three options:
2016
2017* Implicit: set *detect_types* to :const:`PARSE_DECLTYPES`
2018* Explicit: set *detect_types* to :const:`PARSE_COLNAMES`
2019* Both: set *detect_types* to
2020  ``sqlite3.PARSE_DECLTYPES | sqlite3.PARSE_COLNAMES``.
2021  Column names take precedence over declared types.
2022
2023The following example illustrates the implicit and explicit approaches:
2024
2025.. testcode::
2026
2027   class Point:
2028       def __init__(self, x, y):
2029           self.x, self.y = x, y
2030
2031       def __repr__(self):
2032           return f"Point({self.x}, {self.y})"
2033
2034   def adapt_point(point):
2035       return f"{point.x};{point.y}"
2036
2037   def convert_point(s):
2038       x, y = list(map(float, s.split(b";")))
2039       return Point(x, y)
2040
2041   # Register the adapter and converter
2042   sqlite3.register_adapter(Point, adapt_point)
2043   sqlite3.register_converter("point", convert_point)
2044
2045   # 1) Parse using declared types
2046   p = Point(4.0, -3.2)
2047   con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_DECLTYPES)
2048   cur = con.execute("CREATE TABLE test(p point)")
2049
2050   cur.execute("INSERT INTO test(p) VALUES(?)", (p,))
2051   cur.execute("SELECT p FROM test")
2052   print("with declared types:", cur.fetchone()[0])
2053   cur.close()
2054   con.close()
2055
2056   # 2) Parse using column names
2057   con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_COLNAMES)
2058   cur = con.execute("CREATE TABLE test(p)")
2059
2060   cur.execute("INSERT INTO test(p) VALUES(?)", (p,))
2061   cur.execute('SELECT p AS "p [point]" FROM test')
2062   print("with column names:", cur.fetchone()[0])
2063
2064.. testoutput::
2065   :hide:
2066
2067   with declared types: Point(4.0, -3.2)
2068   with column names: Point(4.0, -3.2)
2069
2070
2071.. _sqlite3-adapter-converter-recipes:
2072
2073Adapter and converter recipes
2074^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
2075
2076This section shows recipes for common adapters and converters.
2077
2078.. testcode::
2079
2080   import datetime
2081   import sqlite3
2082
2083   def adapt_date_iso(val):
2084       """Adapt datetime.date to ISO 8601 date."""
2085       return val.isoformat()
2086
2087   def adapt_datetime_iso(val):
2088       """Adapt datetime.datetime to timezone-naive ISO 8601 date."""
2089       return val.isoformat()
2090
2091   def adapt_datetime_epoch(val):
2092       """Adapt datetime.datetime to Unix timestamp."""
2093       return int(val.timestamp())
2094
2095   sqlite3.register_adapter(datetime.date, adapt_date_iso)
2096   sqlite3.register_adapter(datetime.datetime, adapt_datetime_iso)
2097   sqlite3.register_adapter(datetime.datetime, adapt_datetime_epoch)
2098
2099   def convert_date(val):
2100       """Convert ISO 8601 date to datetime.date object."""
2101       return datetime.date.fromisoformat(val.decode())
2102
2103   def convert_datetime(val):
2104       """Convert ISO 8601 datetime to datetime.datetime object."""
2105       return datetime.datetime.fromisoformat(val.decode())
2106
2107   def convert_timestamp(val):
2108       """Convert Unix epoch timestamp to datetime.datetime object."""
2109       return datetime.datetime.fromtimestamp(int(val))
2110
2111   sqlite3.register_converter("date", convert_date)
2112   sqlite3.register_converter("datetime", convert_datetime)
2113   sqlite3.register_converter("timestamp", convert_timestamp)
2114
2115.. testcode::
2116   :hide:
2117
2118   dt = datetime.datetime(2019, 5, 18, 15, 17, 8, 123456)
2119
2120   assert adapt_date_iso(dt.date()) == "2019-05-18"
2121   assert convert_date(b"2019-05-18") == dt.date()
2122
2123   assert adapt_datetime_iso(dt) == "2019-05-18T15:17:08.123456"
2124   assert convert_datetime(b"2019-05-18T15:17:08.123456") == dt
2125
2126   # Using current time as fromtimestamp() returns local date/time.
2127   # Droping microseconds as adapt_datetime_epoch truncates fractional second part.
2128   now = datetime.datetime.now().replace(microsecond=0)
2129   current_timestamp = int(now.timestamp())
2130
2131   assert adapt_datetime_epoch(now) == current_timestamp
2132   assert convert_timestamp(str(current_timestamp).encode()) == now
2133
2134
2135.. _sqlite3-connection-shortcuts:
2136
2137How to use connection shortcut methods
2138^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
2139
2140Using the :meth:`~Connection.execute`,
2141:meth:`~Connection.executemany`, and :meth:`~Connection.executescript`
2142methods of the :class:`Connection` class, your code can
2143be written more concisely because you don't have to create the (often
2144superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
2145objects are created implicitly and these shortcut methods return the cursor
2146objects. This way, you can execute a ``SELECT`` statement and iterate over it
2147directly using only a single call on the :class:`Connection` object.
2148
2149.. testcode::
2150
2151   # Create and fill the table.
2152   con = sqlite3.connect(":memory:")
2153   con.execute("CREATE TABLE lang(name, first_appeared)")
2154   data = [
2155       ("C++", 1985),
2156       ("Objective-C", 1984),
2157   ]
2158   con.executemany("INSERT INTO lang(name, first_appeared) VALUES(?, ?)", data)
2159
2160   # Print the table contents
2161   for row in con.execute("SELECT name, first_appeared FROM lang"):
2162       print(row)
2163
2164   print("I just deleted", con.execute("DELETE FROM lang").rowcount, "rows")
2165
2166   # close() is not a shortcut method and it's not called automatically;
2167   # the connection object should be closed manually
2168   con.close()
2169
2170.. testoutput::
2171   :hide:
2172
2173   ('C++', 1985)
2174   ('Objective-C', 1984)
2175   I just deleted 2 rows
2176
2177
2178.. _sqlite3-connection-context-manager:
2179
2180How to use the connection context manager
2181^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
2182
2183A :class:`Connection` object can be used as a context manager that
2184automatically commits or rolls back open transactions when leaving the body of
2185the context manager.
2186If the body of the :keyword:`with` statement finishes without exceptions,
2187the transaction is committed.
2188If this commit fails,
2189or if the body of the ``with`` statement raises an uncaught exception,
2190the transaction is rolled back.
2191
2192If there is no open transaction upon leaving the body of the ``with`` statement,
2193the context manager is a no-op.
2194
2195.. note::
2196
2197   The context manager neither implicitly opens a new transaction
2198   nor closes the connection.
2199
2200.. testcode::
2201
2202   con = sqlite3.connect(":memory:")
2203   con.execute("CREATE TABLE lang(id INTEGER PRIMARY KEY, name VARCHAR UNIQUE)")
2204
2205   # Successful, con.commit() is called automatically afterwards
2206   with con:
2207       con.execute("INSERT INTO lang(name) VALUES(?)", ("Python",))
2208
2209   # con.rollback() is called after the with block finishes with an exception,
2210   # the exception is still raised and must be caught
2211   try:
2212       with con:
2213           con.execute("INSERT INTO lang(name) VALUES(?)", ("Python",))
2214   except sqlite3.IntegrityError:
2215       print("couldn't add Python twice")
2216
2217   # Connection object used as context manager only commits or rollbacks transactions,
2218   # so the connection object should be closed manually
2219   con.close()
2220
2221.. testoutput::
2222   :hide:
2223
2224   couldn't add Python twice
2225
2226
2227.. _sqlite3-uri-tricks:
2228
2229How to work with SQLite URIs
2230^^^^^^^^^^^^^^^^^^^^^^^^^^^^
2231
2232Some useful URI tricks include:
2233
2234* Open a database in read-only mode:
2235
2236.. doctest::
2237
2238   >>> con = sqlite3.connect("file:tutorial.db?mode=ro", uri=True)
2239   >>> con.execute("CREATE TABLE readonly(data)")
2240   Traceback (most recent call last):
2241   OperationalError: attempt to write a readonly database
2242
2243* Do not implicitly create a new database file if it does not already exist;
2244  will raise :exc:`~sqlite3.OperationalError` if unable to create a new file:
2245
2246.. doctest::
2247
2248   >>> con = sqlite3.connect("file:nosuchdb.db?mode=rw", uri=True)
2249   Traceback (most recent call last):
2250   OperationalError: unable to open database file
2251
2252
2253* Create a shared named in-memory database:
2254
2255.. testcode::
2256
2257   db = "file:mem1?mode=memory&cache=shared"
2258   con1 = sqlite3.connect(db, uri=True)
2259   con2 = sqlite3.connect(db, uri=True)
2260   with con1:
2261       con1.execute("CREATE TABLE shared(data)")
2262       con1.execute("INSERT INTO shared VALUES(28)")
2263   res = con2.execute("SELECT data FROM shared")
2264   assert res.fetchone() == (28,)
2265
2266
2267More information about this feature, including a list of parameters,
2268can be found in the `SQLite URI documentation`_.
2269
2270.. _SQLite URI documentation: https://www.sqlite.org/uri.html
2271
2272
2273.. _sqlite3-howto-row-factory:
2274
2275How to create and use row factories
2276^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
2277
2278By default, :mod:`!sqlite3` represents each row as a :class:`tuple`.
2279If a :class:`!tuple` does not suit your needs,
2280you can use the :class:`sqlite3.Row` class
2281or a custom :attr:`~Cursor.row_factory`.
2282
2283While :attr:`!row_factory` exists as an attribute both on the
2284:class:`Cursor` and the :class:`Connection`,
2285it is recommended to set :class:`Connection.row_factory`,
2286so all cursors created from the connection will use the same row factory.
2287
2288:class:`!Row` provides indexed and case-insensitive named access to columns,
2289with minimal memory overhead and performance impact over a :class:`!tuple`.
2290To use :class:`!Row` as a row factory,
2291assign it to the :attr:`!row_factory` attribute:
2292
2293.. doctest::
2294
2295   >>> con = sqlite3.connect(":memory:")
2296   >>> con.row_factory = sqlite3.Row
2297
2298Queries now return :class:`!Row` objects:
2299
2300.. doctest::
2301
2302   >>> res = con.execute("SELECT 'Earth' AS name, 6378 AS radius")
2303   >>> row = res.fetchone()
2304   >>> row.keys()
2305   ['name', 'radius']
2306   >>> row[0]         # Access by index.
2307   'Earth'
2308   >>> row["name"]    # Access by name.
2309   'Earth'
2310   >>> row["RADIUS"]  # Column names are case-insensitive.
2311   6378
2312
2313You can create a custom :attr:`~Cursor.row_factory`
2314that returns each row as a :class:`dict`, with column names mapped to values:
2315
2316.. testcode::
2317
2318   def dict_factory(cursor, row):
2319       fields = [column[0] for column in cursor.description]
2320       return {key: value for key, value in zip(fields, row)}
2321
2322Using it, queries now return a :class:`!dict` instead of a :class:`!tuple`:
2323
2324.. doctest::
2325
2326   >>> con = sqlite3.connect(":memory:")
2327   >>> con.row_factory = dict_factory
2328   >>> for row in con.execute("SELECT 1 AS a, 2 AS b"):
2329   ...     print(row)
2330   {'a': 1, 'b': 2}
2331
2332The following row factory returns a :term:`named tuple`:
2333
2334.. testcode::
2335
2336   from collections import namedtuple
2337
2338   def namedtuple_factory(cursor, row):
2339       fields = [column[0] for column in cursor.description]
2340       cls = namedtuple("Row", fields)
2341       return cls._make(row)
2342
2343:func:`!namedtuple_factory` can be used as follows:
2344
2345.. doctest::
2346
2347   >>> con = sqlite3.connect(":memory:")
2348   >>> con.row_factory = namedtuple_factory
2349   >>> cur = con.execute("SELECT 1 AS a, 2 AS b")
2350   >>> row = cur.fetchone()
2351   >>> row
2352   Row(a=1, b=2)
2353   >>> row[0]  # Indexed access.
2354   1
2355   >>> row.b   # Attribute access.
2356   2
2357
2358With some adjustments, the above recipe can be adapted to use a
2359:class:`~dataclasses.dataclass`, or any other custom class,
2360instead of a :class:`~collections.namedtuple`.
2361
2362
2363.. _sqlite3-explanation:
2364
2365Explanation
2366-----------
2367
2368.. _sqlite3-controlling-transactions:
2369
2370Transaction control
2371^^^^^^^^^^^^^^^^^^^
2372
2373The :mod:`!sqlite3` module does not adhere to the transaction handling recommended
2374by :pep:`249`.
2375
2376If the connection attribute :attr:`~Connection.isolation_level`
2377is not ``None``,
2378new transactions are implicitly opened before
2379:meth:`~Cursor.execute` and :meth:`~Cursor.executemany` executes
2380``INSERT``, ``UPDATE``, ``DELETE``, or ``REPLACE`` statements;
2381for other statements, no implicit transaction handling is performed.
2382Use the :meth:`~Connection.commit` and :meth:`~Connection.rollback` methods
2383to respectively commit and roll back pending transactions.
2384You can choose the underlying `SQLite transaction behaviour`_ —
2385that is, whether and what type of ``BEGIN`` statements :mod:`!sqlite3`
2386implicitly executes –
2387via the :attr:`~Connection.isolation_level` attribute.
2388
2389If :attr:`~Connection.isolation_level` is set to ``None``,
2390no transactions are implicitly opened at all.
2391This leaves the underlying SQLite library in `autocommit mode`_,
2392but also allows the user to perform their own transaction handling
2393using explicit SQL statements.
2394The underlying SQLite library autocommit mode can be queried using the
2395:attr:`~Connection.in_transaction` attribute.
2396
2397The :meth:`~Cursor.executescript` method implicitly commits
2398any pending transaction before execution of the given SQL script,
2399regardless of the value of :attr:`~Connection.isolation_level`.
2400
2401.. versionchanged:: 3.6
2402   :mod:`!sqlite3` used to implicitly commit an open transaction before DDL
2403   statements.  This is no longer the case.
2404
2405.. _autocommit mode:
2406   https://www.sqlite.org/lang_transaction.html#implicit_versus_explicit_transactions
2407
2408.. _SQLite transaction behaviour:
2409   https://www.sqlite.org/lang_transaction.html#deferred_immediate_and_exclusive_transactions
2410