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