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--------------
12
13SQLite is a C library that provides a lightweight disk-based database that
14doesn't require a separate server process and allows accessing the database
15using a nonstandard variant of the SQL query language. Some applications can use
16SQLite for internal data storage.  It's also possible to prototype an
17application using SQLite and then port the code to a larger database such as
18PostgreSQL or Oracle.
19
20The sqlite3 module was written by Gerhard Häring.  It provides a SQL interface
21compliant with the DB-API 2.0 specification described by :pep:`249`.
22
23To use the module, you must first create a :class:`Connection` object that
24represents the database.  Here the data will be stored in the
25:file:`example.db` file::
26
27   import sqlite3
28   conn = sqlite3.connect('example.db')
29
30You can also supply the special name ``:memory:`` to create a database in RAM.
31
32Once you have a :class:`Connection`, you can create a :class:`Cursor`  object
33and call its :meth:`~Cursor.execute` method to perform SQL commands::
34
35   c = conn.cursor()
36
37   # Create table
38   c.execute('''CREATE TABLE stocks
39                (date text, trans text, symbol text, qty real, price real)''')
40
41   # Insert a row of data
42   c.execute("INSERT INTO stocks VALUES ('2006-01-05','BUY','RHAT',100,35.14)")
43
44   # Save (commit) the changes
45   conn.commit()
46
47   # We can also close the connection if we are done with it.
48   # Just be sure any changes have been committed or they will be lost.
49   conn.close()
50
51The data you've saved is persistent and is available in subsequent sessions::
52
53   import sqlite3
54   conn = sqlite3.connect('example.db')
55   c = conn.cursor()
56
57Usually your SQL operations will need to use values from Python variables.  You
58shouldn't assemble your query using Python's string operations because doing so
59is insecure; it makes your program vulnerable to an SQL injection attack
60(see https://xkcd.com/327/ for humorous example of what can go wrong).
61
62Instead, use the DB-API's parameter substitution.  Put ``?`` as a placeholder
63wherever you want to use a value, and then provide a tuple of values as the
64second argument to the cursor's :meth:`~Cursor.execute` method.  (Other database
65modules may use a different placeholder, such as ``%s`` or ``:1``.) For
66example::
67
68   # Never do this -- insecure!
69   symbol = 'RHAT'
70   c.execute("SELECT * FROM stocks WHERE symbol = '%s'" % symbol)
71
72   # Do this instead
73   t = ('RHAT',)
74   c.execute('SELECT * FROM stocks WHERE symbol=?', t)
75   print(c.fetchone())
76
77   # Larger example that inserts many records at a time
78   purchases = [('2006-03-28', 'BUY', 'IBM', 1000, 45.00),
79                ('2006-04-05', 'BUY', 'MSFT', 1000, 72.00),
80                ('2006-04-06', 'SELL', 'IBM', 500, 53.00),
81               ]
82   c.executemany('INSERT INTO stocks VALUES (?,?,?,?,?)', purchases)
83
84To retrieve data after executing a SELECT statement, you can either treat the
85cursor as an :term:`iterator`, call the cursor's :meth:`~Cursor.fetchone` method to
86retrieve a single matching row, or call :meth:`~Cursor.fetchall` to get a list of the
87matching rows.
88
89This example uses the iterator form::
90
91   >>> for row in c.execute('SELECT * FROM stocks ORDER BY price'):
92           print(row)
93
94   ('2006-01-05', 'BUY', 'RHAT', 100, 35.14)
95   ('2006-03-28', 'BUY', 'IBM', 1000, 45.0)
96   ('2006-04-06', 'SELL', 'IBM', 500, 53.0)
97   ('2006-04-05', 'BUY', 'MSFT', 1000, 72.0)
98
99
100.. seealso::
101
102   https://github.com/ghaering/pysqlite
103      The pysqlite web page -- sqlite3 is developed externally under the name
104      "pysqlite".
105
106   https://www.sqlite.org
107      The SQLite web page; the documentation describes the syntax and the
108      available data types for the supported SQL dialect.
109
110   https://www.w3schools.com/sql/
111      Tutorial, reference and examples for learning SQL syntax.
112
113   :pep:`249` - Database API Specification 2.0
114      PEP written by Marc-André Lemburg.
115
116
117.. _sqlite3-module-contents:
118
119Module functions and constants
120------------------------------
121
122
123.. data:: version
124
125   The version number of this module, as a string. This is not the version of
126   the SQLite library.
127
128
129.. data:: version_info
130
131   The version number of this module, as a tuple of integers. This is not the
132   version of the SQLite library.
133
134
135.. data:: sqlite_version
136
137   The version number of the run-time SQLite library, as a string.
138
139
140.. data:: sqlite_version_info
141
142   The version number of the run-time SQLite library, as a tuple of integers.
143
144
145.. data:: PARSE_DECLTYPES
146
147   This constant is meant to be used with the *detect_types* parameter of the
148   :func:`connect` function.
149
150   Setting it makes the :mod:`sqlite3` module parse the declared type for each
151   column it returns.  It will parse out the first word of the declared type,
152   i. e.  for "integer primary key", it will parse out "integer", or for
153   "number(10)" it will parse out "number". Then for that column, it will look
154   into the converters dictionary and use the converter function registered for
155   that type there.
156
157
158.. data:: PARSE_COLNAMES
159
160   This constant is meant to be used with the *detect_types* parameter of the
161   :func:`connect` function.
162
163   Setting this makes the SQLite interface parse the column name for each column it
164   returns.  It will look for a string formed [mytype] in there, and then decide
165   that 'mytype' is the type of the column. It will try to find an entry of
166   'mytype' in the converters dictionary and then use the converter function found
167   there to return the value. The column name found in :attr:`Cursor.description`
168   is only the first word of the column name, i.  e. if you use something like
169   ``'as "x [datetime]"'`` in your SQL, then we will parse out everything until the
170   first blank for the column name: the column name would simply be "x".
171
172
173.. function:: connect(database[, timeout, detect_types, isolation_level, check_same_thread, factory, cached_statements, uri])
174
175   Opens a connection to the SQLite database file *database*. By default returns a
176   :class:`Connection` object, unless a custom *factory* is given.
177
178   *database* is a :term:`path-like object` giving the pathname (absolute or
179   relative to the current  working directory) of the database file to be opened.
180   You can use ``":memory:"`` to open a database connection to a database that
181   resides in RAM instead of on disk.
182
183   When a database is accessed by multiple connections, and one of the processes
184   modifies the database, the SQLite database is locked until that transaction is
185   committed. The *timeout* parameter specifies how long the connection should wait
186   for the lock to go away until raising an exception. The default for the timeout
187   parameter is 5.0 (five seconds).
188
189   For the *isolation_level* parameter, please see the
190   :attr:`~Connection.isolation_level` property of :class:`Connection` objects.
191
192   SQLite natively supports only the types TEXT, INTEGER, REAL, BLOB and NULL. If
193   you want to use other types you must add support for them yourself. The
194   *detect_types* parameter and the using custom **converters** registered with the
195   module-level :func:`register_converter` function allow you to easily do that.
196
197   *detect_types* defaults to 0 (i. e. off, no type detection), you can set it to
198   any combination of :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES` to turn
199   type detection on.
200
201   By default, *check_same_thread* is :const:`True` and only the creating thread may
202   use the connection. If set :const:`False`, the returned connection may be shared
203   across multiple threads. When using multiple threads with the same connection
204   writing operations should be serialized by the user to avoid data corruption.
205
206   By default, the :mod:`sqlite3` module uses its :class:`Connection` class for the
207   connect call.  You can, however, subclass the :class:`Connection` class and make
208   :func:`connect` use your class instead by providing your class for the *factory*
209   parameter.
210
211   Consult the section :ref:`sqlite3-types` of this manual for details.
212
213   The :mod:`sqlite3` module internally uses a statement cache to avoid SQL parsing
214   overhead. If you want to explicitly set the number of statements that are cached
215   for the connection, you can set the *cached_statements* parameter. The currently
216   implemented default is to cache 100 statements.
217
218   If *uri* is true, *database* is interpreted as a URI. This allows you
219   to specify options. For example, to open a database in read-only mode
220   you can use::
221
222       db = sqlite3.connect('file:path/to/database?mode=ro', uri=True)
223
224   More information about this feature, including a list of recognized options, can
225   be found in the `SQLite URI documentation <https://www.sqlite.org/uri.html>`_.
226
227   .. versionchanged:: 3.4
228      Added the *uri* parameter.
229
230   .. versionchanged:: 3.7
231      *database* can now also be a :term:`path-like object`, not only a string.
232
233
234.. function:: register_converter(typename, callable)
235
236   Registers a callable to convert a bytestring from the database into a custom
237   Python type. The callable will be invoked for all database values that are of
238   the type *typename*. Confer the parameter *detect_types* of the :func:`connect`
239   function for how the type detection works. Note that *typename* and the name of
240   the type in your query are matched in case-insensitive manner.
241
242
243.. function:: register_adapter(type, callable)
244
245   Registers a callable to convert the custom Python type *type* into one of
246   SQLite's supported types. The callable *callable* accepts as single parameter
247   the Python value, and must return a value of the following types: int,
248   float, str or bytes.
249
250
251.. function:: complete_statement(sql)
252
253   Returns :const:`True` if the string *sql* contains one or more complete SQL
254   statements terminated by semicolons. It does not verify that the SQL is
255   syntactically correct, only that there are no unclosed string literals and the
256   statement is terminated by a semicolon.
257
258   This can be used to build a shell for SQLite, as in the following example:
259
260
261   .. literalinclude:: ../includes/sqlite3/complete_statement.py
262
263
264.. function:: enable_callback_tracebacks(flag)
265
266   By default you will not get any tracebacks in user-defined functions,
267   aggregates, converters, authorizer callbacks etc. If you want to debug them,
268   you can call this function with *flag* set to ``True``. Afterwards, you will
269   get tracebacks from callbacks on ``sys.stderr``. Use :const:`False` to
270   disable the feature again.
271
272
273.. _sqlite3-connection-objects:
274
275Connection Objects
276------------------
277
278.. class:: Connection
279
280   A SQLite database connection has the following attributes and methods:
281
282   .. attribute:: isolation_level
283
284      Get or set the current default isolation level. :const:`None` for autocommit mode or
285      one of "DEFERRED", "IMMEDIATE" or "EXCLUSIVE". See section
286      :ref:`sqlite3-controlling-transactions` for a more detailed explanation.
287
288   .. attribute:: in_transaction
289
290      :const:`True` if a transaction is active (there are uncommitted changes),
291      :const:`False` otherwise.  Read-only attribute.
292
293      .. versionadded:: 3.2
294
295   .. method:: cursor(factory=Cursor)
296
297      The cursor method accepts a single optional parameter *factory*. If
298      supplied, this must be a callable returning an instance of :class:`Cursor`
299      or its subclasses.
300
301   .. method:: commit()
302
303      This method commits the current transaction. If you don't call this method,
304      anything you did since the last call to ``commit()`` is not visible from
305      other database connections. If you wonder why you don't see the data you've
306      written to the database, please check you didn't forget to call this method.
307
308   .. method:: rollback()
309
310      This method rolls back any changes to the database since the last call to
311      :meth:`commit`.
312
313   .. method:: close()
314
315      This closes the database connection. Note that this does not automatically
316      call :meth:`commit`. If you just close your database connection without
317      calling :meth:`commit` first, your changes will be lost!
318
319   .. method:: execute(sql[, parameters])
320
321      This is a nonstandard shortcut that creates a cursor object by calling
322      the :meth:`~Connection.cursor` method, calls the cursor's
323      :meth:`~Cursor.execute` method with the *parameters* given, and returns
324      the cursor.
325
326   .. method:: executemany(sql[, parameters])
327
328      This is a nonstandard shortcut that creates a cursor object by
329      calling the :meth:`~Connection.cursor` method, calls the cursor's
330      :meth:`~Cursor.executemany` method with the *parameters* given, and
331      returns the cursor.
332
333   .. method:: executescript(sql_script)
334
335      This is a nonstandard shortcut that creates a cursor object by
336      calling the :meth:`~Connection.cursor` method, calls the cursor's
337      :meth:`~Cursor.executescript` method with the given *sql_script*, and
338      returns the cursor.
339
340   .. method:: create_function(name, num_params, func)
341
342      Creates a user-defined function that you can later use from within SQL
343      statements under the function name *name*. *num_params* is the number of
344      parameters the function accepts (if *num_params* is -1, the function may
345      take any number of arguments), and *func* is a Python callable that is
346      called as the SQL function.
347
348      The function can return any of the types supported by SQLite: bytes, str, int,
349      float and ``None``.
350
351      Example:
352
353      .. literalinclude:: ../includes/sqlite3/md5func.py
354
355
356   .. method:: create_aggregate(name, num_params, aggregate_class)
357
358      Creates a user-defined aggregate function.
359
360      The aggregate class must implement a ``step`` method, which accepts the number
361      of parameters *num_params* (if *num_params* is -1, the function may take
362      any number of arguments), and a ``finalize`` method which will return the
363      final result of the aggregate.
364
365      The ``finalize`` method can return any of the types supported by SQLite:
366      bytes, str, int, float and ``None``.
367
368      Example:
369
370      .. literalinclude:: ../includes/sqlite3/mysumaggr.py
371
372
373   .. method:: create_collation(name, callable)
374
375      Creates a collation with the specified *name* and *callable*. The callable will
376      be passed two string arguments. It should return -1 if the first is ordered
377      lower than the second, 0 if they are ordered equal and 1 if the first is ordered
378      higher than the second.  Note that this controls sorting (ORDER BY in SQL) so
379      your comparisons don't affect other SQL operations.
380
381      Note that the callable will get its parameters as Python bytestrings, which will
382      normally be encoded in UTF-8.
383
384      The following example shows a custom collation that sorts "the wrong way":
385
386      .. literalinclude:: ../includes/sqlite3/collation_reverse.py
387
388      To remove a collation, call ``create_collation`` with ``None`` as callable::
389
390         con.create_collation("reverse", None)
391
392
393   .. method:: interrupt()
394
395      You can call this method from a different thread to abort any queries that might
396      be executing on the connection. The query will then abort and the caller will
397      get an exception.
398
399
400   .. method:: set_authorizer(authorizer_callback)
401
402      This routine registers a callback. The callback is invoked for each attempt to
403      access a column of a table in the database. The callback should return
404      :const:`SQLITE_OK` if access is allowed, :const:`SQLITE_DENY` if the entire SQL
405      statement should be aborted with an error and :const:`SQLITE_IGNORE` if the
406      column should be treated as a NULL value. These constants are available in the
407      :mod:`sqlite3` module.
408
409      The first argument to the callback signifies what kind of operation is to be
410      authorized. The second and third argument will be arguments or :const:`None`
411      depending on the first argument. The 4th argument is the name of the database
412      ("main", "temp", etc.) if applicable. The 5th argument is the name of the
413      inner-most trigger or view that is responsible for the access attempt or
414      :const:`None` if this access attempt is directly from input SQL code.
415
416      Please consult the SQLite documentation about the possible values for the first
417      argument and the meaning of the second and third argument depending on the first
418      one. All necessary constants are available in the :mod:`sqlite3` module.
419
420
421   .. method:: set_progress_handler(handler, n)
422
423      This routine registers a callback. The callback is invoked for every *n*
424      instructions of the SQLite virtual machine. This is useful if you want to
425      get called from SQLite during long-running operations, for example to update
426      a GUI.
427
428      If you want to clear any previously installed progress handler, call the
429      method with :const:`None` for *handler*.
430
431      Returning a non-zero value from the handler function will terminate the
432      currently executing query and cause it to raise an :exc:`OperationalError`
433      exception.
434
435
436   .. method:: set_trace_callback(trace_callback)
437
438      Registers *trace_callback* to be called for each SQL statement that is
439      actually executed by the SQLite backend.
440
441      The only argument passed to the callback is the statement (as string) that
442      is being executed. The return value of the callback is ignored. Note that
443      the backend does not only run statements passed to the :meth:`Cursor.execute`
444      methods.  Other sources include the transaction management of the Python
445      module and the execution of triggers defined in the current database.
446
447      Passing :const:`None` as *trace_callback* will disable the trace callback.
448
449      .. versionadded:: 3.3
450
451
452   .. method:: enable_load_extension(enabled)
453
454      This routine allows/disallows the SQLite engine to load SQLite extensions
455      from shared libraries.  SQLite extensions can define new functions,
456      aggregates or whole new virtual table implementations.  One well-known
457      extension is the fulltext-search extension distributed with SQLite.
458
459      Loadable extensions are disabled by default. See [#f1]_.
460
461      .. versionadded:: 3.2
462
463      .. literalinclude:: ../includes/sqlite3/load_extension.py
464
465   .. method:: load_extension(path)
466
467      This routine loads a SQLite extension from a shared library.  You have to
468      enable extension loading with :meth:`enable_load_extension` before you can
469      use this routine.
470
471      Loadable extensions are disabled by default. See [#f1]_.
472
473      .. versionadded:: 3.2
474
475   .. attribute:: row_factory
476
477      You can change this attribute to a callable that accepts the cursor and the
478      original row as a tuple and will return the real result row.  This way, you can
479      implement more advanced ways of returning results, such  as returning an object
480      that can also access columns by name.
481
482      Example:
483
484      .. literalinclude:: ../includes/sqlite3/row_factory.py
485
486      If returning a tuple doesn't suffice and you want name-based access to
487      columns, you should consider setting :attr:`row_factory` to the
488      highly-optimized :class:`sqlite3.Row` type. :class:`Row` provides both
489      index-based and case-insensitive name-based access to columns with almost no
490      memory overhead. It will probably be better than your own custom
491      dictionary-based approach or even a db_row based solution.
492
493      .. XXX what's a db_row-based solution?
494
495
496   .. attribute:: text_factory
497
498      Using this attribute you can control what objects are returned for the ``TEXT``
499      data type. By default, this attribute is set to :class:`str` and the
500      :mod:`sqlite3` module will return Unicode objects for ``TEXT``. If you want to
501      return bytestrings instead, you can set it to :class:`bytes`.
502
503      You can also set it to any other callable that accepts a single bytestring
504      parameter and returns the resulting object.
505
506      See the following example code for illustration:
507
508      .. literalinclude:: ../includes/sqlite3/text_factory.py
509
510
511   .. attribute:: total_changes
512
513      Returns the total number of database rows that have been modified, inserted, or
514      deleted since the database connection was opened.
515
516
517   .. method:: iterdump
518
519      Returns an iterator to dump the database in an SQL text format.  Useful when
520      saving an in-memory database for later restoration.  This function provides
521      the same capabilities as the :kbd:`.dump` command in the :program:`sqlite3`
522      shell.
523
524      Example::
525
526         # Convert file existing_db.db to SQL dump file dump.sql
527         import sqlite3
528
529         con = sqlite3.connect('existing_db.db')
530         with open('dump.sql', 'w') as f:
531             for line in con.iterdump():
532                 f.write('%s\n' % line)
533
534
535   .. method:: backup(target, *, pages=0, progress=None, name="main", sleep=0.250)
536
537      This method makes a backup of a SQLite database even while it's being accessed
538      by other clients, or concurrently by the same connection.  The copy will be
539      written into the mandatory argument *target*, that must be another
540      :class:`Connection` instance.
541
542      By default, or when *pages* is either ``0`` or a negative integer, the entire
543      database is copied in a single step; otherwise the method performs a loop
544      copying up to *pages* pages at a time.
545
546      If *progress* is specified, it must either be ``None`` or a callable object that
547      will be executed at each iteration with three integer arguments, respectively
548      the *status* of the last iteration, the *remaining* number of pages still to be
549      copied and the *total* number of pages.
550
551      The *name* argument specifies the database name that will be copied: it must be
552      a string containing either ``"main"``, the default, to indicate the main
553      database, ``"temp"`` to indicate the temporary database or the name specified
554      after the ``AS`` keyword in an ``ATTACH DATABASE`` statement for an attached
555      database.
556
557      The *sleep* argument specifies the number of seconds to sleep by between
558      successive attempts to backup remaining pages, can be specified either as an
559      integer or a floating point value.
560
561      Example 1, copy an existing database into another::
562
563         import sqlite3
564
565         def progress(status, remaining, total):
566             print(f'Copied {total-remaining} of {total} pages...')
567
568         con = sqlite3.connect('existing_db.db')
569         with sqlite3.connect('backup.db') as bck:
570             con.backup(bck, pages=1, progress=progress)
571
572      Example 2, copy an existing database into a transient copy::
573
574         import sqlite3
575
576         source = sqlite3.connect('existing_db.db')
577         dest = sqlite3.connect(':memory:')
578         source.backup(dest)
579
580      Availability: SQLite 3.6.11 or higher
581
582      .. versionadded:: 3.7
583
584
585.. _sqlite3-cursor-objects:
586
587Cursor Objects
588--------------
589
590.. class:: Cursor
591
592   A :class:`Cursor` instance has the following attributes and methods.
593
594   .. index:: single: ? (question mark); in SQL statements
595   .. index:: single: : (colon); in SQL statements
596
597   .. method:: execute(sql[, parameters])
598
599      Executes an SQL statement. The SQL statement may be parameterized (i. e.
600      placeholders instead of SQL literals). The :mod:`sqlite3` module supports two
601      kinds of placeholders: question marks (qmark style) and named placeholders
602      (named style).
603
604      Here's an example of both styles:
605
606      .. literalinclude:: ../includes/sqlite3/execute_1.py
607
608      :meth:`execute` will only execute a single SQL statement. If you try to execute
609      more than one statement with it, it will raise a :exc:`.Warning`. Use
610      :meth:`executescript` if you want to execute multiple SQL statements with one
611      call.
612
613
614   .. method:: executemany(sql, seq_of_parameters)
615
616      Executes an SQL command against all parameter sequences or mappings found in
617      the sequence *seq_of_parameters*.  The :mod:`sqlite3` module also allows
618      using an :term:`iterator` yielding parameters instead of a sequence.
619
620      .. literalinclude:: ../includes/sqlite3/executemany_1.py
621
622      Here's a shorter example using a :term:`generator`:
623
624      .. literalinclude:: ../includes/sqlite3/executemany_2.py
625
626
627   .. method:: executescript(sql_script)
628
629      This is a nonstandard convenience method for executing multiple SQL statements
630      at once. It issues a ``COMMIT`` statement first, then executes the SQL script it
631      gets as a parameter.
632
633      *sql_script* can be an instance of :class:`str`.
634
635      Example:
636
637      .. literalinclude:: ../includes/sqlite3/executescript.py
638
639
640   .. method:: fetchone()
641
642      Fetches the next row of a query result set, returning a single sequence,
643      or :const:`None` when no more data is available.
644
645
646   .. method:: fetchmany(size=cursor.arraysize)
647
648      Fetches the next set of rows of a query result, returning a list.  An empty
649      list is returned when no more rows are available.
650
651      The number of rows to fetch per call is specified by the *size* parameter.
652      If it is not given, the cursor's arraysize determines the number of rows
653      to be fetched. The method should try to fetch as many rows as indicated by
654      the size parameter. If this is not possible due to the specified number of
655      rows not being available, fewer rows may be returned.
656
657      Note there are performance considerations involved with the *size* parameter.
658      For optimal performance, it is usually best to use the arraysize attribute.
659      If the *size* parameter is used, then it is best for it to retain the same
660      value from one :meth:`fetchmany` call to the next.
661
662   .. method:: fetchall()
663
664      Fetches all (remaining) rows of a query result, returning a list.  Note that
665      the cursor's arraysize attribute can affect the performance of this operation.
666      An empty list is returned when no rows are available.
667
668   .. method:: close()
669
670      Close the cursor now (rather than whenever ``__del__`` is called).
671
672      The cursor will be unusable from this point forward; a :exc:`ProgrammingError`
673      exception will be raised if any operation is attempted with the cursor.
674
675   .. attribute:: rowcount
676
677      Although the :class:`Cursor` class of the :mod:`sqlite3` module implements this
678      attribute, the database engine's own support for the determination of "rows
679      affected"/"rows selected" is quirky.
680
681      For :meth:`executemany` statements, the number of modifications are summed up
682      into :attr:`rowcount`.
683
684      As required by the Python DB API Spec, the :attr:`rowcount` attribute "is -1 in
685      case no ``executeXX()`` has been performed on the cursor or the rowcount of the
686      last operation is not determinable by the interface". This includes ``SELECT``
687      statements because we cannot determine the number of rows a query produced
688      until all rows were fetched.
689
690      With SQLite versions before 3.6.5, :attr:`rowcount` is set to 0 if
691      you make a ``DELETE FROM table`` without any condition.
692
693   .. attribute:: lastrowid
694
695      This read-only attribute provides the rowid of the last modified row. It is
696      only set if you issued an ``INSERT`` or a ``REPLACE`` statement using the
697      :meth:`execute` method.  For operations other than ``INSERT`` or
698      ``REPLACE`` or when :meth:`executemany` is called, :attr:`lastrowid` is
699      set to :const:`None`.
700
701      If the ``INSERT`` or ``REPLACE`` statement failed to insert the previous
702      successful rowid is returned.
703
704      .. versionchanged:: 3.6
705         Added support for the ``REPLACE`` statement.
706
707   .. attribute:: arraysize
708
709      Read/write attribute that controls the number of rows returned by :meth:`fetchmany`.
710      The default value is 1 which means a single row would be fetched per call.
711
712   .. attribute:: description
713
714      This read-only attribute provides the column names of the last query. To
715      remain compatible with the Python DB API, it returns a 7-tuple for each
716      column where the last six items of each tuple are :const:`None`.
717
718      It is set for ``SELECT`` statements without any matching rows as well.
719
720   .. attribute:: connection
721
722      This read-only attribute provides the SQLite database :class:`Connection`
723      used by the :class:`Cursor` object.  A :class:`Cursor` object created by
724      calling :meth:`con.cursor() <Connection.cursor>` will have a
725      :attr:`connection` attribute that refers to *con*::
726
727         >>> con = sqlite3.connect(":memory:")
728         >>> cur = con.cursor()
729         >>> cur.connection == con
730         True
731
732.. _sqlite3-row-objects:
733
734Row Objects
735-----------
736
737.. class:: Row
738
739   A :class:`Row` instance serves as a highly optimized
740   :attr:`~Connection.row_factory` for :class:`Connection` objects.
741   It tries to mimic a tuple in most of its features.
742
743   It supports mapping access by column name and index, iteration,
744   representation, equality testing and :func:`len`.
745
746   If two :class:`Row` objects have exactly the same columns and their
747   members are equal, they compare equal.
748
749   .. method:: keys
750
751      This method returns a list of column names. Immediately after a query,
752      it is the first member of each tuple in :attr:`Cursor.description`.
753
754   .. versionchanged:: 3.5
755      Added support of slicing.
756
757Let's assume we initialize a table as in the example given above::
758
759   conn = sqlite3.connect(":memory:")
760   c = conn.cursor()
761   c.execute('''create table stocks
762   (date text, trans text, symbol text,
763    qty real, price real)''')
764   c.execute("""insert into stocks
765             values ('2006-01-05','BUY','RHAT',100,35.14)""")
766   conn.commit()
767   c.close()
768
769Now we plug :class:`Row` in::
770
771   >>> conn.row_factory = sqlite3.Row
772   >>> c = conn.cursor()
773   >>> c.execute('select * from stocks')
774   <sqlite3.Cursor object at 0x7f4e7dd8fa80>
775   >>> r = c.fetchone()
776   >>> type(r)
777   <class 'sqlite3.Row'>
778   >>> tuple(r)
779   ('2006-01-05', 'BUY', 'RHAT', 100.0, 35.14)
780   >>> len(r)
781   5
782   >>> r[2]
783   'RHAT'
784   >>> r.keys()
785   ['date', 'trans', 'symbol', 'qty', 'price']
786   >>> r['qty']
787   100.0
788   >>> for member in r:
789   ...     print(member)
790   ...
791   2006-01-05
792   BUY
793   RHAT
794   100.0
795   35.14
796
797
798.. _sqlite3-exceptions:
799
800Exceptions
801----------
802
803.. exception:: Warning
804
805   A subclass of :exc:`Exception`.
806
807.. exception:: Error
808
809   The base class of the other exceptions in this module.  It is a subclass
810   of :exc:`Exception`.
811
812.. exception:: DatabaseError
813
814   Exception raised for errors that are related to the database.
815
816.. exception:: IntegrityError
817
818   Exception raised when the relational integrity of the database is affected,
819   e.g. a foreign key check fails.  It is a subclass of :exc:`DatabaseError`.
820
821.. exception:: ProgrammingError
822
823   Exception raised for programming errors, e.g. table not found or already
824   exists, syntax error in the SQL statement, wrong number of parameters
825   specified, etc.  It is a subclass of :exc:`DatabaseError`.
826
827.. exception:: OperationalError
828
829   Exception raised for errors that are related to the database's operation
830   and not necessarily under the control of the programmer, e.g. an unexpected
831   disconnect occurs, the data source name is not found, a transaction could
832   not be processed, etc.  It is a subclass of :exc:`DatabaseError`.
833
834.. exception:: NotSupportedError
835
836   Exception raised in case a method or database API was used which is not
837   supported by the database, e.g. calling the :meth:`~Connection.rollback`
838   method on a connection that does not support transaction or has
839   transactions turned off.  It is a subclass of :exc:`DatabaseError`.
840
841
842.. _sqlite3-types:
843
844SQLite and Python types
845-----------------------
846
847
848Introduction
849^^^^^^^^^^^^
850
851SQLite natively supports the following types: ``NULL``, ``INTEGER``,
852``REAL``, ``TEXT``, ``BLOB``.
853
854The following Python types can thus be sent to SQLite without any problem:
855
856+-------------------------------+-------------+
857| Python type                   | SQLite type |
858+===============================+=============+
859| :const:`None`                 | ``NULL``    |
860+-------------------------------+-------------+
861| :class:`int`                  | ``INTEGER`` |
862+-------------------------------+-------------+
863| :class:`float`                | ``REAL``    |
864+-------------------------------+-------------+
865| :class:`str`                  | ``TEXT``    |
866+-------------------------------+-------------+
867| :class:`bytes`                | ``BLOB``    |
868+-------------------------------+-------------+
869
870
871This is how SQLite types are converted to Python types by default:
872
873+-------------+----------------------------------------------+
874| SQLite type | Python type                                  |
875+=============+==============================================+
876| ``NULL``    | :const:`None`                                |
877+-------------+----------------------------------------------+
878| ``INTEGER`` | :class:`int`                                 |
879+-------------+----------------------------------------------+
880| ``REAL``    | :class:`float`                               |
881+-------------+----------------------------------------------+
882| ``TEXT``    | depends on :attr:`~Connection.text_factory`, |
883|             | :class:`str` by default                      |
884+-------------+----------------------------------------------+
885| ``BLOB``    | :class:`bytes`                               |
886+-------------+----------------------------------------------+
887
888The type system of the :mod:`sqlite3` module is extensible in two ways: you can
889store additional Python types in a SQLite database via object adaptation, and
890you can let the :mod:`sqlite3` module convert SQLite types to different Python
891types via converters.
892
893
894Using adapters to store additional Python types in SQLite databases
895^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
896
897As described before, SQLite supports only a limited set of types natively. To
898use other Python types with SQLite, you must **adapt** them to one of the
899sqlite3 module's supported types for SQLite: one of NoneType, int, float,
900str, bytes.
901
902There are two ways to enable the :mod:`sqlite3` module to adapt a custom Python
903type to one of the supported ones.
904
905
906Letting your object adapt itself
907""""""""""""""""""""""""""""""""
908
909This is a good approach if you write the class yourself. Let's suppose you have
910a class like this::
911
912   class Point:
913       def __init__(self, x, y):
914           self.x, self.y = x, y
915
916Now you want to store the point in a single SQLite column.  First you'll have to
917choose one of the supported types first to be used for representing the point.
918Let's just use str and separate the coordinates using a semicolon. Then you need
919to give your class a method ``__conform__(self, protocol)`` which must return
920the converted value. The parameter *protocol* will be :class:`PrepareProtocol`.
921
922.. literalinclude:: ../includes/sqlite3/adapter_point_1.py
923
924
925Registering an adapter callable
926"""""""""""""""""""""""""""""""
927
928The other possibility is to create a function that converts the type to the
929string representation and register the function with :meth:`register_adapter`.
930
931.. literalinclude:: ../includes/sqlite3/adapter_point_2.py
932
933The :mod:`sqlite3` module has two default adapters for Python's built-in
934:class:`datetime.date` and :class:`datetime.datetime` types.  Now let's suppose
935we want to store :class:`datetime.datetime` objects not in ISO representation,
936but as a Unix timestamp.
937
938.. literalinclude:: ../includes/sqlite3/adapter_datetime.py
939
940
941Converting SQLite values to custom Python types
942^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
943
944Writing an adapter lets you send custom Python types to SQLite. But to make it
945really useful we need to make the Python to SQLite to Python roundtrip work.
946
947Enter converters.
948
949Let's go back to the :class:`Point` class. We stored the x and y coordinates
950separated via semicolons as strings in SQLite.
951
952First, we'll define a converter function that accepts the string as a parameter
953and constructs a :class:`Point` object from it.
954
955.. note::
956
957   Converter functions **always** get called with a :class:`bytes` object, no
958   matter under which data type you sent the value to SQLite.
959
960::
961
962   def convert_point(s):
963       x, y = map(float, s.split(b";"))
964       return Point(x, y)
965
966Now you need to make the :mod:`sqlite3` module know that what you select from
967the database is actually a point. There are two ways of doing this:
968
969* Implicitly via the declared type
970
971* Explicitly via the column name
972
973Both ways are described in section :ref:`sqlite3-module-contents`, in the entries
974for the constants :const:`PARSE_DECLTYPES` and :const:`PARSE_COLNAMES`.
975
976The following example illustrates both approaches.
977
978.. literalinclude:: ../includes/sqlite3/converter_point.py
979
980
981Default adapters and converters
982^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
983
984There are default adapters for the date and datetime types in the datetime
985module. They will be sent as ISO dates/ISO timestamps to SQLite.
986
987The default converters are registered under the name "date" for
988:class:`datetime.date` and under the name "timestamp" for
989:class:`datetime.datetime`.
990
991This way, you can use date/timestamps from Python without any additional
992fiddling in most cases. The format of the adapters is also compatible with the
993experimental SQLite date/time functions.
994
995The following example demonstrates this.
996
997.. literalinclude:: ../includes/sqlite3/pysqlite_datetime.py
998
999If a timestamp stored in SQLite has a fractional part longer than 6
1000numbers, its value will be truncated to microsecond precision by the
1001timestamp converter.
1002
1003
1004.. _sqlite3-controlling-transactions:
1005
1006Controlling Transactions
1007------------------------
1008
1009The underlying ``sqlite3`` library operates in ``autocommit`` mode by default,
1010but the Python :mod:`sqlite3` module by default does not.
1011
1012``autocommit`` mode means that statements that modify the database take effect
1013immediately.  A ``BEGIN`` or ``SAVEPOINT`` statement disables ``autocommit``
1014mode, and a ``COMMIT``, a ``ROLLBACK``, or a ``RELEASE`` that ends the
1015outermost transaction, turns ``autocommit`` mode back on.
1016
1017The Python :mod:`sqlite3` module by default issues a ``BEGIN`` statement
1018implicitly before a Data Modification Language (DML) statement (i.e.
1019``INSERT``/``UPDATE``/``DELETE``/``REPLACE``).
1020
1021You can control which kind of ``BEGIN`` statements :mod:`sqlite3` implicitly
1022executes via the *isolation_level* parameter to the :func:`connect`
1023call, or via the :attr:`isolation_level` property of connections.
1024If you specify no *isolation_level*, a plain ``BEGIN`` is used, which is
1025equivalent to specifying ``DEFERRED``.  Other possible values are ``IMMEDIATE``
1026and ``EXCLUSIVE``.
1027
1028You can disable the :mod:`sqlite3` module's implicit transaction management by
1029setting :attr:`isolation_level` to ``None``.  This will leave the underlying
1030``sqlite3`` library operating in ``autocommit`` mode.  You can then completely
1031control the transaction state by explicitly issuing ``BEGIN``, ``ROLLBACK``,
1032``SAVEPOINT``, and ``RELEASE`` statements in your code.
1033
1034.. versionchanged:: 3.6
1035   :mod:`sqlite3` used to implicitly commit an open transaction before DDL
1036   statements.  This is no longer the case.
1037
1038
1039Using :mod:`sqlite3` efficiently
1040--------------------------------
1041
1042
1043Using shortcut methods
1044^^^^^^^^^^^^^^^^^^^^^^
1045
1046Using the nonstandard :meth:`execute`, :meth:`executemany` and
1047:meth:`executescript` methods of the :class:`Connection` object, your code can
1048be written more concisely because you don't have to create the (often
1049superfluous) :class:`Cursor` objects explicitly. Instead, the :class:`Cursor`
1050objects are created implicitly and these shortcut methods return the cursor
1051objects. This way, you can execute a ``SELECT`` statement and iterate over it
1052directly using only a single call on the :class:`Connection` object.
1053
1054.. literalinclude:: ../includes/sqlite3/shortcut_methods.py
1055
1056
1057Accessing columns by name instead of by index
1058^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1059
1060One useful feature of the :mod:`sqlite3` module is the built-in
1061:class:`sqlite3.Row` class designed to be used as a row factory.
1062
1063Rows wrapped with this class can be accessed both by index (like tuples) and
1064case-insensitively by name:
1065
1066.. literalinclude:: ../includes/sqlite3/rowclass.py
1067
1068
1069Using the connection as a context manager
1070^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
1071
1072Connection objects can be used as context managers
1073that automatically commit or rollback transactions.  In the event of an
1074exception, the transaction is rolled back; otherwise, the transaction is
1075committed:
1076
1077.. literalinclude:: ../includes/sqlite3/ctx_manager.py
1078
1079
1080Common issues
1081-------------
1082
1083Multithreading
1084^^^^^^^^^^^^^^
1085
1086Older SQLite versions had issues with sharing connections between threads.
1087That's why the Python module disallows sharing connections and cursors between
1088threads. If you still try to do so, you will get an exception at runtime.
1089
1090The only exception is calling the :meth:`~Connection.interrupt` method, which
1091only makes sense to call from a different thread.
1092
1093.. rubric:: Footnotes
1094
1095.. [#f1] The sqlite3 module is not built with loadable extension support by
1096   default, because some platforms (notably Mac OS X) have SQLite
1097   libraries which are compiled without this feature. To get loadable
1098   extension support, you must pass --enable-loadable-sqlite-extensions to
1099   configure.
1100