summaryrefslogtreecommitdiffstats
path: root/Doc/library/sqlite3.rst
blob: 48549e06b3885e1588ecf6640a114331bdedb82f (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
:mod:`sqlite3` --- DB-API 2.0 interface for SQLite databases
============================================================

.. module:: sqlite3
   :synopsis: A DB-API 2.0 implementation using SQLite 3.x.

.. sectionauthor:: Gerhard Häring <gh@ghaering.de>

**Source code:** :source:`Lib/sqlite3/`

--------------

SQLite is a C library that provides a lightweight disk-based database that
doesn't require a separate server process and allows accessing the database
using a nonstandard variant of the SQL query language. Some applications can use
SQLite for internal data storage.  It's also possible to prototype an
application using SQLite and then port the code to a larger database such as
PostgreSQL or Oracle.

The sqlite3 module was written by Gerhard Häring.  It provides an SQL interface
compliant with the DB-API 2.0 specification described by :pep:`249`, and
requires SQLite 3.7.15 or newer.

To use the module, start by creating a :class:`Connection` object that
represents the database.  Here the data will be stored in the
:file:`example.db` file::

   import sqlite3
   con = sqlite3.connect('example.db')

The special path name ``:memory:`` can be provided to create a temporary
database in RAM.

Once a :class:`Connection` has been established, create a :class:`Cursor` object
and call its :meth:`~Cursor.execute` method to perform SQL commands::

   cur = con.cursor()

   # Create table
   cur.execute('''CREATE TABLE stocks
                  (date text, trans text, symbol text, qty real, price real)''')

   # Insert a row of data
   cur.execute("INSERT INTO stocks VALUES ('2006-01-05','BUY','RHAT',100,35.14)")

   # Save (commit) the changes
   con.commit()

   # We can also close the connection if we are done with it.
   # Just be sure any changes have been committed or they will be lost.
   con.close()

The saved data is persistent: it can be reloaded in a subsequent session even
after restarting the Python interpreter::

   import sqlite3
   con = sqlite3.connect('example.db')
   cur = con.cursor()

To retrieve data after executing a SELECT statement, either treat the cursor as
an :term:`iterator`, call the cursor's :meth:`~Cursor.fetchone` method to
retrieve a single matching row, or call :meth:`~Cursor.fetchall` to get a list
of the matching rows.

This example uses the iterator form::

   >>> for row in cur.execute('SELECT * FROM stocks ORDER BY price'):
           print(row)

   ('2006-01-05', 'BUY', 'RHAT', 100, 35.14)
   ('2006-03-28', 'BUY', 'IBM', 1000, 45.0)
   ('2006-04-06', 'SELL', 'IBM', 500, 53.0)
   ('2006-04-05', 'BUY', 'MSFT', 1000, 72.0)


.. _sqlite3-placeholders:

SQL operations usually need to use values from Python variables. However,
beware of using Python's string operations to assemble queries, as they
are vulnerable to SQL injection attacks (see the `xkcd webcomic
<https://xkcd.com/327/>`_ for a humorous example of what can go wrong)::

   # Never do this -- insecure!
   symbol = 'RHAT'
   cur.execute("SELECT * FROM stocks WHERE symbol = '%s'" % symbol)

Instead, use the DB-API's parameter substitution. To insert a variable into a
query string, use a placeholder in the string, and substitute the actual values
into the query by providing them as a :class:`tuple` of values to the second
argument of the cursor's :meth:`~Cursor.execute` method. An SQL statement may
use one of two kinds of placeholders: question marks (qmark style) or named
placeholders (named style). For the qmark style, ``parameters`` must be a
:term:`sequence <sequence>`. For the named style, it can be either a
:term:`sequence <sequence>` or :class:`dict` instance. The length of the
:term:`sequence <sequence>` must match the number of placeholders, or a
:exc:`ProgrammingError` is raised. If a :class:`dict` is given, it must contain
keys for all named parameters. Any extra items are ignored. Here's an example of
both styles:

.. literalinclude:: ../includes/sqlite3/execute_1.py


.. seealso::

   https://www.sqlite.org
      The SQLite web page; the documentation describes the syntax and the
      available data types for the supported SQL dialect.

   https://www.w3schools.com/sql/
      Tutorial, reference and examples for learning SQL syntax.

   :pep:`249` - Database API Specification 2.0
      PEP written by Marc-André Lemburg.


.. _sqlite3-module-contents:

Module functions and constants
------------------------------


.. data:: apilevel

   String constant stating the supported DB-API level. Required by the DB-API.
   Hard-coded to ``"2.0"``.

.. data:: paramstyle

   String constant stating the type of parameter marker formatting expected by
   the :mod:`sqlite3` module. Required by the DB-API. Hard-coded to
   ``"qmark"``.

   .. note::

      The :mod:`sqlite3` module supports both ``qmark`` and ``numeric`` DB-API
      parameter styles, because that is what the underlying SQLite library
      supports. However, the DB-API does not allow multiple values for
      the ``paramstyle`` attribute.

.. data:: version

   The version number of this module, as a string. This is not the version of
   the SQLite library.


.. data:: version_info

   The version number of this module, as a tuple of integers. This is not the
   version of the SQLite library.


.. data:: sqlite_version

   The version number of the run-time SQLite library, as a string.


.. data:: sqlite_version_info

   The version number of the run-time SQLite library, as a tuple of integers.


.. data:: threadsafety

   Integer constant required by the DB-API 2.0, stating the level of thread
   safety the :mod:`sqlite3` module supports. This attribute is set based on
   the default `threading mode <https://sqlite.org/threadsafe.html>`_ the
   underlying SQLite library is compiled with. The SQLite threading modes are:

     1. **Single-thread**: In this mode, all mutexes are disabled and SQLite is
        unsafe to use in more than a single thread at once.
     2. **Multi-thread**: In this mode, SQLite can be safely used by multiple
        threads provided that no single database connection is used
        simultaneously in two or more threads.
     3. **Serialized**: In serialized mode, SQLite can be safely used by
        multiple threads with no restriction.

   The mappings from SQLite threading modes to DB-API 2.0 threadsafety levels
   are as follows:

   +------------------+-----------------+----------------------+-------------------------------+
   | SQLite threading | `threadsafety`_ | `SQLITE_THREADSAFE`_ | DB-API 2.0 meaning            |
   | mode             |                 |                      |                               |
   +==================+=================+======================+===============================+
   | single-thread    | 0               | 0                    | Threads may not share the     |
   |                  |                 |                      | module                        |
   +------------------+-----------------+----------------------+-------------------------------+
   | multi-thread     | 1               | 2                    | Threads may share the module, |
   |                  |                 |                      | but not connections           |
   +------------------+-----------------+----------------------+-------------------------------+
   | serialized       | 3               | 1                    | Threads may share the module, |
   |                  |                 |                      | connections and cursors       |
   +------------------+-----------------+----------------------+-------------------------------+

   .. _threadsafety: https://peps.python.org/pep-0249/#threadsafety
   .. _SQLITE_THREADSAFE: https://sqlite.org/compile.html#threadsafe

   .. versionchanged:: 3.11
      Set *threadsafety* dynamically instead of hard-coding it to ``1``.

.. data:: PARSE_DECLTYPES

   Pass this flag value to the *detect_types* parameter of
   :func:`connect` to look up a converter function using
   the declared types for each column.
   The types are declared when the database table is created.
   ``sqlite3`` will look up a converter function using the first word of the
   declared type as the converter dictionary key.
   For example:


   .. code-block:: sql

      CREATE TABLE test(
         i integer primary key,  ! will look up a converter named "integer"
         p point,                ! will look up a converter named "point"
         n number(10)            ! will look up a converter named "number"
       )

   This flag may be combined with :const:`PARSE_COLNAMES` using the ``|``
   (bitwise or) operator.


.. data:: PARSE_COLNAMES

   Pass this flag value to the *detect_types* parameter of
   :func:`connect` to look up a converter function by
   using the type name, parsed from the query column name,
   as the converter dictionary key.
   The type name must be wrapped in square brackets (``[]``).

   .. code-block:: sql

      SELECT p as "p [point]" FROM test;  ! will look up converter "point"

   This flag may be combined with :const:`PARSE_DECLTYPES` using the ``|``
   (bitwise or) operator.


.. function:: connect(database[, timeout, detect_types, isolation_level, check_same_thread, factory, cached_statements, uri])

   Opens a connection to the SQLite database file *database*. By default returns a
   :class:`Connection` object, unless a custom *factory* is given.

   *database* is a :term:`path-like object` giving the pathname (absolute or
   relative to the current  working directory) of the database file to be opened.
   You can use ``":memory:"`` to open a database connection to a database that
   resides in RAM instead of on disk.

   When a database is accessed by multiple connections, and one of the processes
   modifies the database, the SQLite database is locked until that transaction is
   committed. The *timeout* parameter specifies how long the connection should wait
   for the lock to go away until raising an exception. The default for the timeout
   parameter is 5.0 (five seconds).

   For the *isolation_level* parameter, please see the
   :attr:`~Connection.isolation_level` property of :class:`Connection` objects.

   SQLite natively supports only the types TEXT, INTEGER, REAL, BLOB and NULL. If
   you want to use other types you must add support for them yourself. The
   *detect_types* parameter and using custom **converters** registered with the
   module-level :func:`register_converter` function allow you to easily do that.

   *detect_types* defaults to 0 (type detection disabled).
   Set it to any combination (using ``|``, bitwise or) of
   :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`
   to enable type detection.
   Column names takes precedence over declared types if both flags are set.
   Types cannot be detected for generated fields (for example ``max(data)``),
   even when the *detect_types* parameter is set.
   In such cases, the returned type is :class:`str`.

   By default, *check_same_thread* is :const:`True` and only the creating thread may
   use the connection. If set :const:`False`, the returned connection may be shared
   across multiple threads. When using multiple threads with the same connection
   writing operations should be serialized by the user to avoid data corruption.

   By default, the :mod:`sqlite3` module uses its :class:`Connection` class for the
   connect call.  You can, however, subclass the :class:`Connection` class and make
   :func:`connect` use your class instead by providing your class for the *factory*
   parameter.

   Consult the section :ref:`sqlite3-types` of this manual for details.

   The :mod:`sqlite3` module internally uses a statement cache to avoid SQL parsing
   overhead. If you want to explicitly set the number of statements that are cached
   for the connection, you can set the *cached_statements* parameter. The currently
   implemented default is to cache 128 statements.

   If *uri* is :const:`True`, *database* is interpreted as a
   :abbr:`URI (Uniform Resource Identifier)` with a file path and an optional
   query string.  The scheme part *must* be ``"file:"``.  The path can be a
   relative or absolute file path.  The query string allows us to pass
   parameters to SQLite. Some useful URI tricks include::

       # Open a database in read-only mode.
       con = sqlite3.connect("file:template.db?mode=ro", uri=True)

       # Don't implicitly create a new database file if it does not already exist.
       # Will raise sqlite3.OperationalError if unable to open a database file.
       con = sqlite3.connect("file:nosuchdb.db?mode=rw", uri=True)

       # Create a shared named in-memory database.
       con1 = sqlite3.connect("file:mem1?mode=memory&cache=shared", uri=True)
       con2 = sqlite3.connect("file:mem1?mode=memory&cache=shared", uri=True)
       con1.executescript("create table t(t); insert into t values(28);")
       rows = con2.execute("select * from t").fetchall()

   More information about this feature, including a list of recognized
   parameters, can be found in the
   `SQLite URI documentation <https://www.sqlite.org/uri.html>`_.

   .. audit-event:: sqlite3.connect database sqlite3.connect
   .. audit-event:: sqlite3.connect/handle connection_handle sqlite3.connect

   .. versionchanged:: 3.4
      Added the *uri* parameter.

   .. versionchanged:: 3.7
      *database* can now also be a :term:`path-like object`, not only a string.

   .. versionchanged:: 3.10
      Added the ``sqlite3.connect/handle`` auditing event.


.. function:: register_converter(typename, converter)

   Register the *converter* callable to convert SQLite objects of type
   *typename* into a Python object of a specific type.
   The converter is invoked for all SQLite values of type *typename*;
   it is passed a :class:`bytes` object and should return an object of the
   desired Python type.
   Consult the parameter *detect_types* of
   :func:`connect` for information regarding how type detection works.

   Note: *typename* and the name of the type in your query are matched
   case-insensitively.


.. function:: register_adapter(type, adapter)

   Register an *adapter* callable to adapt the Python type *type* into an
   SQLite type.
   The adapter is called with a Python object of type *type* as its sole
   argument, and must return a value of a
   :ref:`type that SQLite natively understands<sqlite3-types>`.


.. function:: complete_statement(statement)

   Returns :const:`True` if the string *statement* contains one or more complete SQL
   statements terminated by semicolons. It does not verify that the SQL is
   syntactically correct, only that there are no unclosed string literals and the
   statement is terminated by a semicolon.

   This can be used to build a shell for SQLite, as in the following example:


   .. literalinclude:: ../includes/sqlite3/complete_statement.py


.. function:: enable_callback_tracebacks(flag)

   By default you will not get any tracebacks in user-defined functions,
   aggregates, converters, authorizer callbacks etc. If you want to debug them,
   you can call this function with *flag* set to :const:`True`. Afterwards, you
   will get tracebacks from callbacks on :data:`sys.stderr`. Use :const:`False`
   to disable the feature again.

   Register an :func:`unraisable hook handler <sys.unraisablehook>` for an
   improved debug experience::

      >>> import sqlite3
      >>> sqlite3.enable_callback_tracebacks(True)
      >>> cx = sqlite3.connect(":memory:")
      >>> cx.set_trace_callback(lambda stmt: 5/0)
      >>> cx.execute("select 1")
      Exception ignored in: <function <lambda> at 0x10b4e3ee0>
      Traceback (most recent call last):
        File "<stdin>", line 1, in <lambda>
      ZeroDivisionError: division by zero
      >>> import sys
      >>> sys.unraisablehook = lambda unraisable: print(unraisable)
      >>> cx.execute("select 1")
      UnraisableHookArgs(exc_type=<class 'ZeroDivisionError'>, exc_value=ZeroDivisionError('division by zero'), exc_traceback=<traceback object at 0x10b559900>, err_msg=None, object=<function <lambda> at 0x10b4e3ee0>)
      <sqlite3.Cursor object at 0x10b1fe840>


.. _sqlite3-connection-objects:

Connection Objects
------------------

.. class:: Connection

   An SQLite database connection has the following attributes and methods:

   .. attribute:: isolation_level

      Get or set the current default isolation level. :const:`None` for autocommit mode or
      one of "DEFERRED", "IMMEDIATE" or "EXCLUSIVE". See section
      :ref:`sqlite3-controlling-transactions` for a more detailed explanation.

   .. attribute:: in_transaction

      :const:`True` if a transaction is active (there are uncommitted changes),
      :const:`False` otherwise.  Read-only attribute.

      .. versionadded:: 3.2

   .. method:: cursor(factory=Cursor)

      The cursor method accepts a single optional parameter *factory*. If
      supplied, this must be a callable returning an instance of :class:`Cursor`
      or its subclasses.

   .. method:: blobopen(table, column, row, /, *, readonly=False, name="main")

      Open a :class:`Blob` handle to the :abbr:`BLOB (Binary Large OBject)`
      located in table name *table*, column name *column*, and row index *row*
      of database *name*.
      When *readonly* is :const:`True` the blob is opened without write
      permissions.
      Trying to open a blob in a ``WITHOUT ROWID`` table will raise
      :exc:`OperationalError`.

      .. note::

         The blob size cannot be changed using the :class:`Blob` class.
         Use the SQL function ``zeroblob`` to create a blob with a fixed size.

      .. versionadded:: 3.11

   .. method:: commit()

      Commit any pending transaction to the database.
      If there is no open transaction, this method is a no-op.

   .. method:: rollback()

      Roll back to the start of any pending transaction.
      If there is no open transaction, this method is a no-op.

   .. method:: close()

      Close the database connection.
      Any pending transaction is not committed implicitly;
      make sure to :meth:`commit` before closing
      to avoid losing pending changes.

   .. method:: execute(sql[, parameters])

      Create a new :class:`Cursor` object and call
      :meth:`~Cursor.execute` on it with the given *sql* and *parameters*.
      Return the new cursor object.

   .. method:: executemany(sql[, parameters])

      Create a new :class:`Cursor` object and call
      :meth:`~Cursor.executemany` on it with the given *sql* and *parameters*.
      Return the new cursor object.

   .. method:: executescript(sql_script)

      Create a new :class:`Cursor` object and call
      :meth:`~Cursor.executescript` on it with the given *sql_script*.
      Return the new cursor object.

   .. method:: create_function(name, narg, func, *, deterministic=False)

      Creates a user-defined function that you can later use from within SQL
      statements under the function name *name*. *narg* is the number of
      parameters the function accepts (if *narg* is -1, the function may
      take any number of arguments), and *func* is a Python callable that is
      called as the SQL function. If *deterministic* is true, the created function
      is marked as `deterministic <https://sqlite.org/deterministic.html>`_, which
      allows SQLite to perform additional optimizations. This flag is supported by
      SQLite 3.8.3 or higher, :exc:`NotSupportedError` will be raised if used
      with older versions.

      The function can return any of the types supported by SQLite: bytes, str, int,
      float and ``None``.

      .. versionchanged:: 3.8
         The *deterministic* parameter was added.

      Example:

      .. literalinclude:: ../includes/sqlite3/md5func.py


   .. method:: create_aggregate(name, n_arg, aggregate_class)

      Creates a user-defined aggregate function.

      The aggregate class must implement a ``step`` method, which accepts the number
      of parameters *n_arg* (if *n_arg* is -1, the function may take
      any number of arguments), and a ``finalize`` method which will return the
      final result of the aggregate.

      The ``finalize`` method can return any of the types supported by SQLite:
      bytes, str, int, float and ``None``.

      Example:

      .. literalinclude:: ../includes/sqlite3/mysumaggr.py


   .. method:: create_window_function(name, num_params, aggregate_class, /)

      Creates user-defined aggregate window function *name*.

      *aggregate_class* must implement the following methods:

      * ``step``: adds a row to the current window
      * ``value``: returns the current value of the aggregate
      * ``inverse``: removes a row from the current window
      * ``finalize``: returns the final value of the aggregate

      ``step`` and ``value`` accept *num_params* number of parameters,
      unless *num_params* is ``-1``, in which case they may take any number of
      arguments.  ``finalize`` and ``value`` can return any of the types
      supported by SQLite:
      :class:`bytes`, :class:`str`, :class:`int`, :class:`float`, and
      :const:`None`.  Call :meth:`create_window_function` with
      *aggregate_class* set to :const:`None` to clear window function *name*.

      Aggregate window functions are supported by SQLite 3.25.0 and higher.
      :exc:`NotSupportedError` will be raised if used with older versions.

      .. versionadded:: 3.11

      Example:

      .. literalinclude:: ../includes/sqlite3/sumintwindow.py


   .. method:: create_collation(name, callable)

      Create a collation named *name* using the collating function *callable*.
      *callable* is passed two :class:`string <str>` arguments,
      and it should return an :class:`integer <int>`:

      * ``1`` if the first is ordered higher than the second
      * ``-1`` if the first is ordered lower than the second
      * ``0`` if they are ordered equal

      The following example shows a reverse sorting collation:

      .. literalinclude:: ../includes/sqlite3/collation_reverse.py

      Remove a collation function by setting *callable* to :const:`None`.

      .. versionchanged:: 3.11
         The collation name can contain any Unicode character.  Earlier, only
         ASCII characters were allowed.


   .. method:: interrupt()

      You can call this method from a different thread to abort any queries that might
      be executing on the connection. The query will then abort and the caller will
      get an exception.


   .. method:: set_authorizer(authorizer_callback)

      This routine registers a callback. The callback is invoked for each attempt to
      access a column of a table in the database. The callback should return
      :const:`SQLITE_OK` if access is allowed, :const:`SQLITE_DENY` if the entire SQL
      statement should be aborted with an error and :const:`SQLITE_IGNORE` if the
      column should be treated as a NULL value. These constants are available in the
      :mod:`sqlite3` module.

      The first argument to the callback signifies what kind of operation is to be
      authorized. The second and third argument will be arguments or :const:`None`
      depending on the first argument. The 4th argument is the name of the database
      ("main", "temp", etc.) if applicable. The 5th argument is the name of the
      inner-most trigger or view that is responsible for the access attempt or
      :const:`None` if this access attempt is directly from input SQL code.

      Please consult the SQLite documentation about the possible values for the first
      argument and the meaning of the second and third argument depending on the first
      one. All necessary constants are available in the :mod:`sqlite3` module.

      Passing :const:`None` as *authorizer_callback* will disable the authorizer.

      .. versionchanged:: 3.11
         Added support for disabling the authorizer using :const:`None`.


   .. method:: set_progress_handler(progress_handler, n)

      This routine registers a callback. The callback is invoked for every *n*
      instructions of the SQLite virtual machine. This is useful if you want to
      get called from SQLite during long-running operations, for example to update
      a GUI.

      If you want to clear any previously installed progress handler, call the
      method with :const:`None` for *progress_handler*.

      Returning a non-zero value from the handler function will terminate the
      currently executing query and cause it to raise an :exc:`OperationalError`
      exception.


   .. method:: set_trace_callback(trace_callback)

      Registers *trace_callback* to be called for each SQL statement that is
      actually executed by the SQLite backend.

      The only argument passed to the callback is the statement (as
      :class:`str`) that is being executed. The return value of the callback is
      ignored. Note that the backend does not only run statements passed to the
      :meth:`Cursor.execute` methods.  Other sources include the
      :ref:`transaction management <sqlite3-controlling-transactions>` of the
      sqlite3 module and the execution of triggers defined in the current
      database.

      Passing :const:`None` as *trace_callback* will disable the trace callback.

      .. note::
         Exceptions raised in the trace callback are not propagated. As a
         development and debugging aid, use
         :meth:`~sqlite3.enable_callback_tracebacks` to enable printing
         tracebacks from exceptions raised in the trace callback.

      .. versionadded:: 3.3


   .. method:: enable_load_extension(enabled)

      This routine allows/disallows the SQLite engine to load SQLite extensions
      from shared libraries.  SQLite extensions can define new functions,
      aggregates or whole new virtual table implementations.  One well-known
      extension is the fulltext-search extension distributed with SQLite.

      Loadable extensions are disabled by default. See [#f1]_.

      .. audit-event:: sqlite3.enable_load_extension connection,enabled sqlite3.Connection.enable_load_extension

      .. versionadded:: 3.2

      .. versionchanged:: 3.10
         Added the ``sqlite3.enable_load_extension`` auditing event.

      .. literalinclude:: ../includes/sqlite3/load_extension.py

   .. method:: load_extension(path)

      This routine loads an SQLite extension from a shared library.  You have to
      enable extension loading with :meth:`enable_load_extension` before you can
      use this routine.

      Loadable extensions are disabled by default. See [#f1]_.

      .. audit-event:: sqlite3.load_extension connection,path sqlite3.Connection.load_extension

      .. versionadded:: 3.2

      .. versionchanged:: 3.10
         Added the ``sqlite3.load_extension`` auditing event.

   .. attribute:: row_factory

      You can change this attribute to a callable that accepts the cursor and the
      original row as a tuple and will return the real result row.  This way, you can
      implement more advanced ways of returning results, such  as returning an object
      that can also access columns by name.

      Example:

      .. literalinclude:: ../includes/sqlite3/row_factory.py

      If returning a tuple doesn't suffice and you want name-based access to
      columns, you should consider setting :attr:`row_factory` to the
      highly optimized :class:`sqlite3.Row` type. :class:`Row` provides both
      index-based and case-insensitive name-based access to columns with almost no
      memory overhead. It will probably be better than your own custom
      dictionary-based approach or even a db_row based solution.

      .. XXX what's a db_row-based solution?


   .. attribute:: text_factory

      Using this attribute you can control what objects are returned for the ``TEXT``
      data type. By default, this attribute is set to :class:`str` and the
      :mod:`sqlite3` module will return :class:`str` objects for ``TEXT``.
      If you want to return :class:`bytes` instead, you can set it to :class:`bytes`.

      You can also set it to any other callable that accepts a single bytestring
      parameter and returns the resulting object.

      See the following example code for illustration:

      .. literalinclude:: ../includes/sqlite3/text_factory.py


   .. attribute:: total_changes

      Returns the total number of database rows that have been modified, inserted, or
      deleted since the database connection was opened.


   .. method:: iterdump

      Returns an iterator to dump the database in an SQL text format.  Useful when
      saving an in-memory database for later restoration.  This function provides
      the same capabilities as the :kbd:`.dump` command in the :program:`sqlite3`
      shell.

      Example::

         # Convert file existing_db.db to SQL dump file dump.sql
         import sqlite3

         con = sqlite3.connect('existing_db.db')
         with open('dump.sql', 'w') as f:
             for line in con.iterdump():
                 f.write('%s\n' % line)
         con.close()


   .. method:: backup(target, *, pages=-1, progress=None, name="main", sleep=0.250)

      This method makes a backup of an SQLite database even while it's being accessed
      by other clients, or concurrently by the same connection.  The copy will be
      written into the mandatory argument *target*, that must be another
      :class:`Connection` instance.

      By default, or when *pages* is either ``0`` or a negative integer, the entire
      database is copied in a single step; otherwise the method performs a loop
      copying up to *pages* pages at a time.

      If *progress* is specified, it must either be ``None`` or a callable object that
      will be executed at each iteration with three integer arguments, respectively
      the *status* of the last iteration, the *remaining* number of pages still to be
      copied and the *total* number of pages.

      The *name* argument specifies the database name that will be copied: it must be
      a string containing either ``"main"``, the default, to indicate the main
      database, ``"temp"`` to indicate the temporary database or the name specified
      after the ``AS`` keyword in an ``ATTACH DATABASE`` statement for an attached
      database.

      The *sleep* argument specifies the number of seconds to sleep by between
      successive attempts to backup remaining pages, can be specified either as an
      integer or a floating point value.

      Example 1, copy an existing database into another::

         import sqlite3

         def progress(status, remaining, total):
             print(f'Copied {total-remaining} of {total} pages...')

         con = sqlite3.connect('existing_db.db')
         bck = sqlite3.connect('backup.db')
         with bck:
             con.backup(bck, pages=1, progress=progress)
         bck.close()
         con.close()

      Example 2, copy an existing database into a transient copy::

         import sqlite3

         source = sqlite3.connect('existing_db.db')
         dest = sqlite3.connect(':memory:')
         source.backup(dest)

      .. versionadded:: 3.7


   .. method:: getlimit(category, /)

      Get a connection run-time limit. *category* is the limit category to be
      queried.

      Example, query the maximum length of an SQL statement::

         import sqlite3
         con = sqlite3.connect(":memory:")
         lim = con.getlimit(sqlite3.SQLITE_LIMIT_SQL_LENGTH)
         print(f"SQLITE_LIMIT_SQL_LENGTH={lim}")

      .. versionadded:: 3.11


   .. method:: setlimit(category, limit, /)

      Set a connection run-time limit. *category* is the limit category to be
      set. *limit* is the new limit. If the new limit is a negative number, the
      limit is unchanged.

      Attempts to increase a limit above its hard upper bound are silently
      truncated to the hard upper bound. Regardless of whether or not the limit
      was changed, the prior value of the limit is returned.

      Example, limit the number of attached databases to 1::

         import sqlite3
         con = sqlite3.connect(":memory:")
         con.setlimit(sqlite3.SQLITE_LIMIT_ATTACHED, 1)

      .. versionadded:: 3.11


   .. method:: serialize(*, name="main")

      This method serializes a database into a :class:`bytes` object.  For an
      ordinary on-disk database file, the serialization is just a copy of the
      disk file.  For an in-memory database or a "temp" database, the
      serialization is the same sequence of bytes which would be written to
      disk if that database were backed up to disk.

      *name* is the database to be serialized, and defaults to the main
      database.

      .. note::

         This method is only available if the underlying SQLite library has the
         serialize API.

      .. versionadded:: 3.11


   .. method:: deserialize(data, /, *, name="main")

      This method causes the database connection to disconnect from database
      *name*, and reopen *name* as an in-memory database based on the
      serialization contained in *data*.  Deserialization will raise
      :exc:`OperationalError` if the database connection is currently involved
      in a read transaction or a backup operation.  :exc:`OverflowError` will be
      raised if ``len(data)`` is larger than ``2**63 - 1``, and
      :exc:`DatabaseError` will be raised if *data* does not contain a valid
      SQLite database.

      .. note::

         This method is only available if the underlying SQLite library has the
         deserialize API.

      .. versionadded:: 3.11


.. _sqlite3-cursor-objects:

Cursor Objects
--------------

.. class:: Cursor

   A :class:`Cursor` instance has the following attributes and methods.

   .. index:: single: ? (question mark); in SQL statements
   .. index:: single: : (colon); in SQL statements

   .. method:: execute(sql[, parameters])

      Executes an SQL statement. Values may be bound to the statement using
      :ref:`placeholders <sqlite3-placeholders>`.

      :meth:`execute` will only execute a single SQL statement. If you try to execute
      more than one statement with it, it will raise a :exc:`ProgrammingError`. Use
      :meth:`executescript` if you want to execute multiple SQL statements with one
      call.


   .. method:: executemany(sql, seq_of_parameters)

      Executes a :ref:`parameterized <sqlite3-placeholders>` SQL command
      against all parameter sequences or mappings found in the sequence
      *seq_of_parameters*. The :mod:`sqlite3` module also allows using an
      :term:`iterator` yielding parameters instead of a sequence.

      .. literalinclude:: ../includes/sqlite3/executemany_1.py

      Here's a shorter example using a :term:`generator`:

      .. literalinclude:: ../includes/sqlite3/executemany_2.py


   .. method:: executescript(sql_script)

      This is a nonstandard convenience method for executing multiple SQL statements
      at once. It issues a ``COMMIT`` statement first, then executes the SQL script it
      gets as a parameter.  This method disregards :attr:`isolation_level`; any
      transaction control must be added to *sql_script*.

      *sql_script* can be an instance of :class:`str`.

      Example:

      .. literalinclude:: ../includes/sqlite3/executescript.py


   .. method:: fetchone()

      Fetches the next row of a query result set, returning a single sequence,
      or :const:`None` when no more data is available.


   .. method:: fetchmany(size=cursor.arraysize)

      Fetches the next set of rows of a query result, returning a list.  An empty
      list is returned when no more rows are available.

      The number of rows to fetch per call is specified by the *size* parameter.
      If it is not given, the cursor's arraysize determines the number of rows
      to be fetched. The method should try to fetch as many rows as indicated by
      the size parameter. If this is not possible due to the specified number of
      rows not being available, fewer rows may be returned.

      Note there are performance considerations involved with the *size* parameter.
      For optimal performance, it is usually best to use the arraysize attribute.
      If the *size* parameter is used, then it is best for it to retain the same
      value from one :meth:`fetchmany` call to the next.

   .. method:: fetchall()

      Fetches all (remaining) rows of a query result, returning a list.  Note that
      the cursor's arraysize attribute can affect the performance of this operation.
      An empty list is returned when no rows are available.

   .. method:: close()

      Close the cursor now (rather than whenever ``__del__`` is called).

      The cursor will be unusable from this point forward; a :exc:`ProgrammingError`
      exception will be raised if any operation is attempted with the cursor.

   .. method:: setinputsizes(sizes)

      Required by the DB-API. Does nothing in :mod:`sqlite3`.

   .. method:: setoutputsize(size [, column])

      Required by the DB-API. Does nothing in :mod:`sqlite3`.

   .. attribute:: rowcount

      Although the :class:`Cursor` class of the :mod:`sqlite3` module implements this
      attribute, the database engine's own support for the determination of "rows
      affected"/"rows selected" is quirky.

      For :meth:`executemany` statements, the number of modifications are summed up
      into :attr:`rowcount`.

      As required by the Python DB API Spec, the :attr:`rowcount` attribute "is -1 in
      case no ``executeXX()`` has been performed on the cursor or the rowcount of the
      last operation is not determinable by the interface". This includes ``SELECT``
      statements because we cannot determine the number of rows a query produced
      until all rows were fetched.

   .. attribute:: lastrowid

      This read-only attribute provides the row id of the last inserted row. It
      is only updated after successful ``INSERT`` or ``REPLACE`` statements
      using the :meth:`execute` method.  For other statements, after
      :meth:`executemany` or :meth:`executescript`, or if the insertion failed,
      the value of ``lastrowid`` is left unchanged.  The initial value of
      ``lastrowid`` is :const:`None`.

      .. note::
         Inserts into ``WITHOUT ROWID`` tables are not recorded.

      .. versionchanged:: 3.6
         Added support for the ``REPLACE`` statement.

   .. attribute:: arraysize

      Read/write attribute that controls the number of rows returned by :meth:`fetchmany`.
      The default value is 1 which means a single row would be fetched per call.

   .. attribute:: description

      This read-only attribute provides the column names of the last query. To
      remain compatible with the Python DB API, it returns a 7-tuple for each
      column where the last six items of each tuple are :const:`None`.

      It is set for ``SELECT`` statements without any matching rows as well.

   .. attribute:: connection

      This read-only attribute provides the SQLite database :class:`Connection`
      used by the :class:`Cursor` object.  A :class:`Cursor` object created by
      calling :meth:`con.cursor() <Connection.cursor>` will have a
      :attr:`connection` attribute that refers to *con*::

         >>> con = sqlite3.connect(":memory:")
         >>> cur = con.cursor()
         >>> cur.connection == con
         True

.. _sqlite3-row-objects:

Row Objects
-----------

.. class:: Row

   A :class:`Row` instance serves as a highly optimized
   :attr:`~Connection.row_factory` for :class:`Connection` objects.
   It tries to mimic a tuple in most of its features.

   It supports mapping access by column name and index, iteration,
   representation, equality testing and :func:`len`.

   If two :class:`Row` objects have exactly the same columns and their
   members are equal, they compare equal.

   .. method:: keys

      This method returns a list of column names. Immediately after a query,
      it is the first member of each tuple in :attr:`Cursor.description`.

   .. versionchanged:: 3.5
      Added support of slicing.

Let's assume we initialize a table as in the example given above::

   con = sqlite3.connect(":memory:")
   cur = con.cursor()
   cur.execute('''create table stocks
   (date text, trans text, symbol text,
    qty real, price real)''')
   cur.execute("""insert into stocks
               values ('2006-01-05','BUY','RHAT',100,35.14)""")
   con.commit()
   cur.close()

Now we plug :class:`Row` in::

   >>> con.row_factory = sqlite3.Row
   >>> cur = con.cursor()
   >>> cur.execute('select * from stocks')
   <sqlite3.Cursor object at 0x7f4e7dd8fa80>
   >>> r = cur.fetchone()
   >>> type(r)
   <class 'sqlite3.Row'>
   >>> tuple(r)
   ('2006-01-05', 'BUY', 'RHAT', 100.0, 35.14)
   >>> len(r)
   5
   >>> r[2]
   'RHAT'
   >>> r.keys()
   ['date', 'trans', 'symbol', 'qty', 'price']
   >>> r['qty']
   100.0
   >>> for member in r:
   ...     print(member)
   ...
   2006-01-05
   BUY
   RHAT
   100.0
   35.14


Blob Objects
------------

.. versionadded:: 3.11

.. class:: Blob

   A :class:`Blob` instance is a :term:`file-like object`
   that can read and write data in an SQLite :abbr:`BLOB (Binary Large OBject)`.
   Call :func:`len(blob) <len>` to get the size (number of bytes) of the blob.
   Use indices and :term:`slices <slice>` for direct access to the blob data.

   Use the :class:`Blob` as a :term:`context manager` to ensure that the blob
   handle is closed after use.

   .. literalinclude:: ../includes/sqlite3/blob.py

   .. method:: close()

      Close the blob.

      The blob will be unusable from this point onward.  An
      :class:`~sqlite3.Error` (or subclass) exception will be raised if any
      further operation is attempted with the blob.

   .. method:: read(length=-1, /)

      Read *length* bytes of data from the blob at the current offset position.
      If the end of the blob is reached, the data up to
      :abbr:`EOF (End of File)` will be returned.  When *length* is not
      specified, or is negative, :meth:`~Blob.read` will read until the end of
      the blob.

   .. method:: write(data, /)

      Write *data* to the blob at the current offset.  This function cannot
      change the blob length.  Writing beyond the end of the blob will raise
      :exc:`ValueError`.

   .. method:: tell()

      Return the current access position of the blob.

   .. method:: seek(offset, origin=os.SEEK_SET, /)

      Set the current access position of the blob to *offset*.  The *origin*
      argument defaults to :data:`os.SEEK_SET` (absolute blob positioning).
      Other values for *origin* are :data:`os.SEEK_CUR` (seek relative to the
      current position) and :data:`os.SEEK_END` (seek relative to the blob’s
      end).


.. _sqlite3-exceptions:

Exceptions
----------

The exception hierarchy is defined by the DB-API 2.0 (:pep:`249`).

.. exception:: Warning

   This exception is not currently raised by the ``sqlite3`` module,
   but may be raised by applications using ``sqlite3``,
   for example if a user-defined function truncates data while inserting.
   ``Warning`` is a subclass of :exc:`Exception`.

.. exception:: Error

   The base class of the other exceptions in this module.
   Use this to catch all errors with one single :keyword:`except` statement.
   ``Error`` is a subclass of :exc:`Exception`.

   .. attribute:: sqlite_errorcode

      The numeric error code from the
      `SQLite API <https://sqlite.org/rescode.html>`_

      .. versionadded:: 3.11

   .. attribute:: sqlite_errorname

      The symbolic name of the numeric error code
      from the `SQLite API <https://sqlite.org/rescode.html>`_

      .. versionadded:: 3.11

.. exception:: InterfaceError

   Exception raised for misuse of the low-level SQLite C API.
   In other words, if this exception is raised, it probably indicates a bug in the
   ``sqlite3`` module.
   ``InterfaceError`` is a subclass of :exc:`Error`.

.. exception:: DatabaseError

   Exception raised for errors that are related to the database.
   This serves as the base exception for several types of database errors.
   It is only raised implicitly through the specialised subclasses.
   ``DatabaseError`` is a subclass of :exc:`Error`.

.. exception:: DataError

   Exception raised for errors caused by problems with the processed data,
   like numeric values out of range, and strings which are too long.
   ``DataError`` is a subclass of :exc:`DatabaseError`.

.. exception:: OperationalError

   Exception raised for errors that are related to the database's operation,
   and not necessarily under the control of the programmer.
   For example, the database path is not found,
   or a transaction could not be processed.
   ``OperationalError`` is a subclass of :exc:`DatabaseError`.

.. exception:: IntegrityError

   Exception raised when the relational integrity of the database is affected,
   e.g. a foreign key check fails.  It is a subclass of :exc:`DatabaseError`.

.. exception:: InternalError

   Exception raised when SQLite encounters an internal error.
   If this is raised, it may indicate that there is a problem with the runtime
   SQLite library.
   ``InternalError`` is a subclass of :exc:`DatabaseError`.

.. exception:: ProgrammingError

   Exception raised for ``sqlite3`` API programming errors,
   for example supplying the wrong number of bindings to a query,
   or trying to operate on a closed :class:`Connection`.
   ``ProgrammingError`` is a subclass of :exc:`DatabaseError`.

.. exception:: NotSupportedError

   Exception raised in case a method or database API is not supported by the
   underlying SQLite library. For example, setting *deterministic* to
   :const:`True` in :meth:`~Connection.create_function`, if the underlying SQLite library
   does not support deterministic functions.
   ``NotSupportedError`` is a subclass of :exc:`DatabaseError`.


.. _sqlite3-blob-objects:

.. _sqlite3-types:

SQLite and Python types
-----------------------


Introduction
^^^^^^^^^^^^

SQLite natively supports the following types: ``NULL``, ``INTEGER``,
``REAL``, ``TEXT``, ``BLOB``.

The following Python types can thus be sent to SQLite without any problem:

+-------------------------------+-------------+
| Python type                   | SQLite type |
+===============================+=============+
| :const:`None`                 | ``NULL``    |
+-------------------------------+-------------+
| :class:`int`                  | ``INTEGER`` |
+-------------------------------+-------------+
| :class:`float`                | ``REAL``    |
+-------------------------------+-------------+
| :class:`str`                  | ``TEXT``    |
+-------------------------------+-------------+
| :class:`bytes`                | ``BLOB``    |
+-------------------------------+-------------+


This is how SQLite types are converted to Python types by default:

+-------------+----------------------------------------------+
| SQLite type | Python type                                  |
+=============+==============================================+
| ``NULL``    | :const:`None`                                |
+-------------+----------------------------------------------+
| ``INTEGER`` | :class:`int`                                 |
+-------------+----------------------------------------------+
| ``REAL``    | :class:`float`                               |
+-------------+----------------------------------------------+
| ``TEXT``    | depends on :attr:`~Connection.text_factory`, |
|             | :class:`str` by default                      |
+-------------+----------------------------------------------+
| ``BLOB``    | :class:`bytes`                               |
+-------------+----------------------------------------------+

The type system of the :mod:`sqlite3` module is extensible in two ways: you can
store additional Python types in an SQLite database via object adaptation, and
you can let the :mod:`sqlite3` module convert SQLite types to different Python
types via converters.


Using adapters to store custom Python types in SQLite databases
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

SQLite supports only a limited set of data types natively.
To store custom Python types in SQLite databases, *adapt* them to one of the
:ref:`Python types SQLite natively understands<sqlite3-types>`.

There are two ways to adapt Python objects to SQLite types:
letting your object adapt itself, or using an *adapter callable*.
The latter will take precedence above the former.
For a library that exports a custom type,
it may make sense to enable that type to adapt itself.
As an application developer, it may make more sense to take direct control by
registering custom adapter functions.


Letting your object adapt itself
""""""""""""""""""""""""""""""""

Suppose we have a ``Point`` class that represents a pair of coordinates,
``x`` and ``y``, in a Cartesian coordinate system.
The coordinate pair will be stored as a text string in the database,
using a semicolon to separate the coordinates.
This can be implemented by adding a ``__conform__(self, protocol)``
method which returns the adapted value.
The object passed to *protocol* will be of type :class:`PrepareProtocol`.

.. literalinclude:: ../includes/sqlite3/adapter_point_1.py


Registering an adapter callable
"""""""""""""""""""""""""""""""

The other possibility is to create a function that converts the Python object
to an SQLite-compatible type.
This function can then be registered using :func:`register_adapter`.

.. literalinclude:: ../includes/sqlite3/adapter_point_2.py


Converting SQLite values to custom Python types
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

Writing an adapter lets you convert *from* custom Python types *to* SQLite
values.
To be able to convert *from* SQLite values *to* custom Python types,
we use *converters*.

Let's go back to the :class:`Point` class. We stored the x and y coordinates
separated via semicolons as strings in SQLite.

First, we'll define a converter function that accepts the string as a parameter
and constructs a :class:`Point` object from it.

.. note::

   Converter functions are **always** passed a :class:`bytes` object,
   no matter the underlying SQLite data type.

::

   def convert_point(s):
       x, y = map(float, s.split(b";"))
       return Point(x, y)

We now need to tell ``sqlite3`` when it should convert a given SQLite value.
This is done when connecting to a database, using the *detect_types* parameter
of :func:`connect`. There are three options:

* Implicit: set *detect_types* to :const:`PARSE_DECLTYPES`
* Explicit: set *detect_types* to :const:`PARSE_COLNAMES`
* Both: set *detect_types* to
  ``sqlite3.PARSE_DECLTYPES | sqlite3.PARSE_COLNAMES``.
  Colum names take precedence over declared types.

The following example illustrates the implicit and explicit approaches:

.. literalinclude:: ../includes/sqlite3/converter_point.py


Default adapters and converters
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

There are default adapters for the date and datetime types in the datetime
module. They will be sent as ISO dates/ISO timestamps to SQLite.

The default converters are registered under the name "date" for
:class:`datetime.date` and under the name "timestamp" for
:class:`datetime.datetime`.

This way, you can use date/timestamps from Python without any additional
fiddling in most cases. The format of the adapters is also compatible with the
experimental SQLite date/time functions.

The following example demonstrates this.

.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py

If a timestamp stored in SQLite has a fractional part longer than 6
numbers, its value will be truncated to microsecond precision by the
timestamp converter.

.. note::

   The default "timestamp" converter ignores UTC offsets in the database and
   always returns a naive :class:`datetime.datetime` object. To preserve UTC
   offsets in timestamps, either leave converters disabled, or register an
   offset-aware converter with :func:`register_converter`.


.. _sqlite3-adapter-converter-recipes:

Adapter and Converter Recipes
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

This section shows recipes for common adapters and converters.

.. code-block::

   import datetime
   import sqlite3

   def adapt_date_iso(val):
       """Adapt datetime.date to ISO 8601 date."""
       return val.isoformat()

   def adapt_datetime_iso(val):
       """Adapt datetime.datetime to timezone-naive ISO 8601 date."""
       return val.isoformat()

   def adapt_datetime_epoch(val)
       """Adapt datetime.datetime to Unix timestamp."""
       return int(val.timestamp())

   sqlite3.register_adapter(datetime.date, adapt_date_iso)
   sqlite3.register_adapter(datetime.datetime, adapt_datetime_iso)
   sqlite3.register_adapter(datetime.datetime, adapt_datetime_epoch)

   def convert_date(val):
       """Convert ISO 8601 date to datetime.date object."""
       return datetime.date.fromisoformat(val)

   def convert_datetime(val):
       """Convert ISO 8601 datetime to datetime.datetime object."""
       return datetime.datetime.fromisoformat(val)

   def convert_timestamp(val):
       """Convert Unix epoch timestamp to datetime.datetime object."""
       return datetime.datetime.fromtimestamp(val)

   sqlite3.register_converter("date", convert_date)
   sqlite3.register_converter("datetime", convert_datetime)
   sqlite3.register_converter("timestamp", convert_timestamp)


.. _sqlite3-controlling-transactions:

Controlling Transactions
------------------------

The underlying ``sqlite3`` library operates in ``autocommit`` mode by default,
but the Python :mod:`sqlite3` module by default does not.

``autocommit`` mode means that statements that modify the database take effect
immediately.  A ``BEGIN`` or ``SAVEPOINT`` statement disables ``autocommit``
mode, and a ``COMMIT``, a ``ROLLBACK``, or a ``RELEASE`` that ends the
outermost transaction, turns ``autocommit`` mode back on.

The Python :mod:`sqlite3` module by default issues a ``BEGIN`` statement
implicitly before a Data Modification Language (DML) statement (i.e.
``INSERT``/``UPDATE``/``DELETE``/``REPLACE``).

You can control which kind of ``BEGIN`` statements :mod:`sqlite3` implicitly
executes via the *isolation_level* parameter to the :func:`connect`
call, or via the :attr:`isolation_level` property of connections.
If you specify no *isolation_level*, a plain ``BEGIN`` is used, which is
equivalent to specifying ``DEFERRED``.  Other possible values are ``IMMEDIATE``
and ``EXCLUSIVE``.

You can disable the :mod:`sqlite3` module's implicit transaction management by
setting :attr:`isolation_level` to ``None``.  This will leave the underlying
``sqlite3`` library operating in ``autocommit`` mode.  You can then completely
control the transaction state by explicitly issuing ``BEGIN``, ``ROLLBACK``,
``SAVEPOINT``, and ``RELEASE`` statements in your code.

Note that :meth:`~Cursor.executescript` disregards
:attr:`isolation_level`; any transaction control must be added explicitly.

.. versionchanged:: 3.6
   :mod:`sqlite3` used to implicitly commit an open transaction before DDL
   statements.  This is no longer the case.


Using :mod:`sqlite3` efficiently
--------------------------------


Using shortcut methods
^^^^^^^^^^^^^^^^^^^^^^

Using the nonstandard :meth:`execute`, :meth:`executemany` and
:meth:`executescript` methods of the :class:`Connection` object, your code can
be written more concisely because you don't have to create the (often
superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
objects are created implicitly and these shortcut methods return the cursor
objects. This way, you can execute a ``SELECT`` statement and iterate over it
directly using only a single call on the :class:`Connection` object.

.. literalinclude:: ../includes/sqlite3/shortcut_methods.py


Accessing columns by name instead of by index
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

One useful feature of the :mod:`sqlite3` module is the built-in
:class:`sqlite3.Row` class designed to be used as a row factory.

Rows wrapped with this class can be accessed both by index (like tuples) and
case-insensitively by name:

.. literalinclude:: ../includes/sqlite3/rowclass.py


.. _sqlite3-connection-context-manager:

Using the connection as a context manager
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

A :class:`Connection` object can be used as a context manager that
automatically commits or rolls back open transactions when leaving the body of
the context manager.
If the body of the :keyword:`with` statement finishes without exceptions,
the transaction is committed.
If this commit fails,
or if the body of the ``with`` statement raises an uncaught exception,
the transaction is rolled back.

If there is no open transaction upon leaving the body of the ``with`` statement,
the context manager is a no-op.

.. note::

   The context manager neither implicitly opens a new transaction
   nor closes the connection.

.. literalinclude:: ../includes/sqlite3/ctx_manager.py


.. rubric:: Footnotes

.. [#f1] The sqlite3 module is not built with loadable extension support by
   default, because some platforms (notably macOS) have SQLite
   libraries which are compiled without this feature. To get loadable
   extension support, you must pass the
   :option:`--enable-loadable-sqlite-extensions` option to configure.