sqlite3 --- SQLite データベースに対する DB-API 2.0 インターフェース

ソースコード: Lib/sqlite3/

はじめに

SQLite は、軽量なディスク上のデータベースを提供する C ライブラリです。別のサーバプロセスを用意する必要なく、 SQL クエリー言語の非標準的な一種を使用してデータベースにアクセスできます。一部のアプリケーションは内部データ保存に SQLite を使えます。また、SQLite を使ってアプリケーションのプロトタイプを作り、その後そのコードを PostgreSQL や 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.

This document includes four main sections:

  • Tutorial teaches how to use the sqlite3 module.

  • Reference describes the classes and functions this module defines.

  • How-to guides details how to handle specific tasks.

  • Explanation provides in-depth background on transaction control.

Tutorial

To use the module, start by creating a Connection object that represents the database. Here the data will be stored in the 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 Connection has been established, create a Cursor object and call its 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()

At this point, our database only contains one row:

>>> res = cur.execute('SELECT count(rowid) FROM stocks')
>>> print(res.fetchone())
(1,)

The result is a one-item tuple: one row, with one column. Now, let us insert three more rows of data, using executemany():

>>> data = [
...    ('2006-03-28', 'BUY', 'IBM', 1000, 45.0),
...    ('2006-04-05', 'BUY', 'MSFT', 1000, 72.0),
...    ('2006-04-06', 'SELL', 'IBM', 500, 53.0),
... ]
>>> cur.executemany('INSERT INTO stocks VALUES(?, ?, ?, ?, ?)', data)

Then, retrieve the data by iterating over the result of a SELECT statement:

>>> 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)

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 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 tuple of values to the second argument of the cursor's 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 sequence. For the named style, it can be either a sequence or dict instance. The length of the sequence must match the number of placeholders, or a ProgrammingError is raised. If a dict is given, it must contain keys for all named parameters. Any extra items are ignored. Here's an example of both styles:

import sqlite3

con = sqlite3.connect(":memory:")
cur = con.cursor()
cur.execute("create table lang (name, first_appeared)")

# This is the qmark style:
cur.execute("insert into lang values (?, ?)", ("C", 1972))

# The qmark style used with executemany():
lang_list = [
    ("Fortran", 1957),
    ("Python", 1991),
    ("Go", 2009),
]
cur.executemany("insert into lang values (?, ?)", lang_list)

# And this is the named style:
cur.execute("select * from lang where first_appeared=:year", {"year": 1972})
print(cur.fetchall())

con.close()

参考

https://www.sqlite.org

SQLite のウェブページ。ここの文書ではサポートされる SQL 方言の文法と使えるデータ型を説明しています。

https://www.w3schools.com/sql/

SQL 学習に効くチュートリアル、リファレンス、実例集。

PEP 249 - Database API Specification 2.0

Marc-Andre Lemburg により書かれた PEP。

Reference

モジュールの関数と定数

sqlite3.apilevel

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

sqlite3.paramstyle

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

注釈

The 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.

sqlite3.version

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

sqlite3.version_info

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

sqlite3.sqlite_version

Version number of the runtime SQLite library as a string.

sqlite3.sqlite_version_info

Version number of the runtime SQLite library as a tuple of integers.

sqlite3.threadsafety

Integer constant required by the DB-API 2.0, stating the level of thread safety the sqlite3 module supports. This attribute is set based on the default threading mode 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 mode

threadsafety

SQLITE_THREADSAFE

DB-API 2.0 meaning

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

バージョン 3.11 で変更: Set threadsafety dynamically instead of hard-coding it to 1.

sqlite3.PARSE_DECLTYPES

Pass this flag value to the detect_types parameter of 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:

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 PARSE_COLNAMES using the | (bitwise or) operator.

sqlite3.PARSE_COLNAMES

Pass this flag value to the detect_types parameter of 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 ([]).

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

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

sqlite3.connect(database, timeout=5.0, detect_types=0, isolation_level='DEFERRED', check_same_thread=True, factory=sqlite3.Connection, cached_statements=128, uri=False)

Open a connection to an SQLite database.

パラメータ
  • database (path-like object) -- The path to the database file to be opened. Pass ":memory:" to open a connection to a database that is in RAM instead of on disk.

  • timeout (float) -- How many seconds the connection should wait before raising an exception, if the database is locked by another connection. If another connection opens a transaction to modify the database, it will be locked until that transaction is committed. Default five seconds.

  • detect_types (int) -- Control whether and how data types not natively supported by SQLite are looked up to be converted to Python types, using the converters registered with register_converter(). Set it to any combination (using |, bitwise or) of PARSE_DECLTYPES and PARSE_COLNAMES to enable this. 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; str will be returned instead. By default (0), type detection is disabled.

  • isolation_level (str | None) -- The isolation_level of the connection, controlling whether and how transactions are implicitly opened. Can be "DEFERRED" (default), "EXCLUSIVE" or "IMMEDIATE"; or None to disable opening transactions implicitly. See Transaction control for more.

  • check_same_thread (bool) -- If True (default), only the creating thread may use the connection. If False, the connection may be shared across multiple threads; if so, write operations should be serialized by the user to avoid data corruption.

  • factory (Connection) -- A custom subclass of Connection to create the connection with, if not the default Connection class.

  • cached_statements (int) -- The number of statements that sqlite3 should internally cache for this connection, to avoid parsing overhead. By default, 128 statements.

  • uri (bool) -- If set to True, database is interpreted as a URI with a file path and an optional query string. The scheme part must be "file:", and the path can be relative or absolute. The query string allows passing parameters to SQLite, enabling various Working with SQLite URIs.

戻り値の型

Connection

引数 database を指定して 監査イベント sqlite3.connect を送出します。

引数 connection_handle を指定して 監査イベント sqlite3.connect/handle を送出します。

バージョン 3.4 で追加: The uri parameter.

バージョン 3.7 で変更: database can now also be a path-like object, not only a string.

バージョン 3.10 で追加: The sqlite3.connect/handle auditing event.

sqlite3.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 bytes object and should return an object of the desired Python type. Consult the parameter detect_types of connect() for information regarding how type detection works.

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

sqlite3.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 type that SQLite natively understands.

sqlite3.complete_statement(statement)

Returns 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.

この関数は以下の例にあるような SQLite のシェルを作る際に使われます:

# A minimal SQLite shell for experiments

import sqlite3

con = sqlite3.connect(":memory:")
con.isolation_level = None
cur = con.cursor()

buffer = ""

print("Enter your SQL commands to execute in sqlite3.")
print("Enter a blank line to exit.")

while True:
    line = input()
    if line == "":
        break
    buffer += line
    if sqlite3.complete_statement(buffer):
        try:
            buffer = buffer.strip()
            cur.execute(buffer)

            if buffer.lstrip().upper().startswith("SELECT"):
                print(cur.fetchall())
        except sqlite3.Error as e:
            err_msg = str(e)
            err_code = e.sqlite_errorcode
            err_name = e.sqlite_errorname
            print(f"{err_name} ({err_code}): {err_msg}")
        buffer = ""

con.close()
sqlite3.enable_callback_tracebacks(flag, /)

Enable or disable callback tracebacks. 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 True. Afterwards, you will get tracebacks from callbacks on sys.stderr. Use False to disable the feature again.

Register an unraisable hook handler 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>

Connection objects

class sqlite3.Connection

Each open SQLite database is represented by a Connection object, which is created using sqlite3.connect(). Their main purpose is creating Cursor objects, and Transaction control.

An SQLite database connection has the following attributes and methods:

isolation_level

This attribute controls the transaction handling performed by sqlite3. If set to None, transactions are never implicitly opened. If set to one of "DEFERRED", "IMMEDIATE", or "EXCLUSIVE", corresponding to the underlying SQLite transaction behaviour, implicit transaction management is performed.

If not overridden by the isolation_level parameter of connect(), the default is "", which is an alias for "DEFERRED".

in_transaction

This read-only attribute corresponds to the low-level SQLite autocommit mode.

True if a transaction is active (there are uncommitted changes), False otherwise.

バージョン 3.2 で追加.

cursor(factory=Cursor)

Create and return a Cursor object. The cursor method accepts a single optional parameter factory. If supplied, this must be a callable returning an instance of Cursor or its subclasses.

blobopen(table, column, row, /, *, readonly=False, name='main')

Open a Blob handle to an existing BLOB.

パラメータ
  • table (str) -- The name of the table where the blob is located.

  • column (str) -- The name of the column where the blob is located.

  • row (str) -- The name of the row where the blob is located.

  • readonly (bool) -- Set to True if the blob should be opened without write permissions. Defaults to False.

  • name (str) -- The name of the database where the blob is located. Defaults to "main".

例外

OperationalError -- When trying to open a blob in a WITHOUT ROWID table.

戻り値の型

Blob

注釈

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

バージョン 3.11 で追加.

commit()

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

rollback()

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

close()

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

execute(sql, parameters=(), /)

Create a new Cursor object and call execute() on it with the given sql and parameters. Return the new cursor object.

executemany(sql, parameters, /)

Create a new Cursor object and call executemany() on it with the given sql and parameters. Return the new cursor object.

executescript(sql_script, /)

Create a new Cursor object and call executescript() on it with the given sql_script. Return the new cursor object.

create_function(name, narg, func, *, deterministic=False)

Create or remove a user-defined SQL function.

パラメータ
  • name (str) -- The name of the SQL function.

  • narg (int) -- The number of arguments the SQL function can accept. If -1, it may take any number of arguments.

  • func (callback | None) -- A callable that is called when the SQL function is invoked. The callable must return a type natively supported by SQLite. Set to None to remove an existing SQL function.

  • deterministic (bool) -- If True, the created SQL function is marked as deterministic, which allows SQLite to perform additional optimizations.

例外

NotSupportedError -- If deterministic is used with SQLite versions older than 3.8.3.

バージョン 3.8 で追加: The deterministic parameter.

例:

import sqlite3
import hashlib

def md5sum(t):
    return hashlib.md5(t).hexdigest()

con = sqlite3.connect(":memory:")
con.create_function("md5", 1, md5sum)
cur = con.cursor()
cur.execute("select md5(?)", (b"foo",))
print(cur.fetchone()[0])

con.close()
create_aggregate(name, /, n_arg, aggregate_class)

Create or remove a user-defined SQL aggregate function.

パラメータ
  • name (str) -- The name of the SQL aggregate function.

  • n_arg (int) -- The number of arguments the SQL aggregate function can accept. If -1, it may take any number of arguments.

  • aggregate_class (class | None) --

    A class must implement the following methods:

    The number of arguments that the step() method must accept is controlled by n_arg.

    Set to None to remove an existing SQL aggregate function.

例:

import sqlite3

class MySum:
    def __init__(self):
        self.count = 0

    def step(self, value):
        self.count += value

    def finalize(self):
        return self.count

con = sqlite3.connect(":memory:")
con.create_aggregate("mysum", 1, MySum)
cur = con.cursor()
cur.execute("create table test(i)")
cur.execute("insert into test(i) values (1)")
cur.execute("insert into test(i) values (2)")
cur.execute("select mysum(i) from test")
print(cur.fetchone()[0])

con.close()
create_window_function(name, num_params, aggregate_class, /)

Create or remove a user-defined aggregate window function.

パラメータ
  • name (str) -- The name of the SQL aggregate window function to create or remove.

  • num_params (int) -- The number of arguments the SQL aggregate window function can accept. If -1, it may take any number of arguments.

  • aggregate_class (class | None) --

    A class that must implement the following methods:

    • step(): Add a row to the current window.

    • value(): Return the current value of the aggregate.

    • inverse(): Remove a row from the current window.

    • finalize(): Return the final result of the aggregate as a type natively supported by SQLite.

    The number of arguments that the step() and value() methods must accept is controlled by num_params.

    Set to None to remove an existing SQL aggregate window function.

例外

NotSupportedError -- If used with a version of SQLite older than 3.25.0, which does not support aggregate window functions.

バージョン 3.11 で追加.

例:

# Example taken from https://www.sqlite.org/windowfunctions.html#udfwinfunc
import sqlite3


class WindowSumInt:
    def __init__(self):
        self.count = 0

    def step(self, value):
        """Adds a row to the current window."""
        self.count += value

    def value(self):
        """Returns the current value of the aggregate."""
        return self.count

    def inverse(self, value):
        """Removes a row from the current window."""
        self.count -= value

    def finalize(self):
        """Returns the final value of the aggregate.

        Any clean-up actions should be placed here.
        """
        return self.count


con = sqlite3.connect(":memory:")
cur = con.execute("create table test(x, y)")
values = [
    ("a", 4),
    ("b", 5),
    ("c", 3),
    ("d", 8),
    ("e", 1),
]
cur.executemany("insert into test values(?, ?)", values)
con.create_window_function("sumint", 1, WindowSumInt)
cur.execute("""
    select x, sumint(y) over (
        order by x rows between 1 preceding and 1 following
    ) as sum_y
    from test order by x
""")
print(cur.fetchall())
create_collation(name, callable)

Create a collation named name using the collating function callable. callable is passed two string arguments, and it should return an integer:

  • 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:

import sqlite3

def collate_reverse(string1, string2):
    if string1 == string2:
        return 0
    elif string1 < string2:
        return 1
    else:
        return -1

con = sqlite3.connect(":memory:")
con.create_collation("reverse", collate_reverse)

cur = con.cursor()
cur.execute("create table test(x)")
cur.executemany("insert into test(x) values (?)", [("a",), ("b",)])
cur.execute("select x from test order by x collate reverse")
for row in cur:
    print(row)
con.close()

Remove a collation function by setting callable to None.

バージョン 3.11 で変更: The collation name can contain any Unicode character. Earlier, only ASCII characters were allowed.

interrupt()

Call this method from a different thread to abort any queries that might be executing on the connection. Aborted queries will raise an exception.

set_authorizer(authorizer_callback)

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

コールバックの第一引数はどの種類の操作が許可されるかを決めます。第二第三引数には第一引数に依存して本当に使われる引数か None かが渡されます。第四引数はもし適用されるならばデータベースの名前("main", "temp", etc.)です。第五引数はアクセスを試みる要因となった最も内側のトリガまたはビューの名前、またはアクセスの試みが入力された SQL コードに直接起因するものならば None です。

第一引数に与えることができる値や、その第一引数によって決まる第二第三引数の意味については、SQLite の文書を参考にしてください。必要な定数は全て sqlite3 モジュールに用意されています。

Passing None as authorizer_callback will disable the authorizer.

バージョン 3.11 で変更: Added support for disabling the authorizer using None.

set_progress_handler(progress_handler, n)

Register callable progress_handler to be 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 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 OperationalError exception.

set_trace_callback(trace_callback)

Register callable trace_callback to be invoked for each SQL statement that is actually executed by the SQLite backend.

The only argument passed to the callback is the statement (as 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 Cursor.execute() methods. Other sources include the transaction management of the sqlite3 module and the execution of triggers defined in the current database.

trace_callback として None を渡すと、トレースコールバックを無効にできます。

注釈

Exceptions raised in the trace callback are not propagated. As a development and debugging aid, use enable_callback_tracebacks() to enable printing tracebacks from exceptions raised in the trace callback.

バージョン 3.3 で追加.

enable_load_extension(enabled, /)

Enable the SQLite engine to load SQLite extensions from shared libraries if enabled is True; else, disallow loading SQLite extensions. 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.

注釈

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 --enable-loadable-sqlite-extensions option to configure.

引数 connection, enabled を指定して 監査イベント sqlite3.enable_load_extension を送出します。

バージョン 3.2 で追加.

バージョン 3.10 で変更: Added the sqlite3.enable_load_extension auditing event.

import sqlite3

con = sqlite3.connect(":memory:")

# enable extension loading
con.enable_load_extension(True)

# Load the fulltext search extension
con.execute("select load_extension('./fts3.so')")

# alternatively you can load the extension using an API call:
# con.load_extension("./fts3.so")

# disable extension loading again
con.enable_load_extension(False)

# example from SQLite wiki
con.execute("create virtual table recipe using fts3(name, ingredients)")
con.executescript("""
    insert into recipe (name, ingredients) values ('broccoli stew', 'broccoli peppers cheese tomatoes');
    insert into recipe (name, ingredients) values ('pumpkin stew', 'pumpkin onions garlic celery');
    insert into recipe (name, ingredients) values ('broccoli pie', 'broccoli cheese onions flour');
    insert into recipe (name, ingredients) values ('pumpkin pie', 'pumpkin sugar flour butter');
    """)
for row in con.execute("select rowid, name, ingredients from recipe where name match 'pie'"):
    print(row)

con.close()
load_extension(path, /)

Load an SQLite extension from a shared library located at path. Enable extension loading with enable_load_extension() before calling this method.

引数 connection, path を指定して 監査イベント sqlite3.load_extension を送出します。

バージョン 3.2 で追加.

バージョン 3.10 で変更: Added the sqlite3.load_extension auditing event.

row_factory

A callable that accepts two arguments, a Cursor object and the raw row results as a tuple, and returns a custom object representing an SQLite row.

例:

import sqlite3

def dict_factory(cursor, row):
    d = {}
    for idx, col in enumerate(cursor.description):
        d[col[0]] = row[idx]
    return d

con = sqlite3.connect(":memory:")
con.row_factory = dict_factory
cur = con.cursor()
cur.execute("select 1 as a")
print(cur.fetchone()["a"])

con.close()

If returning a tuple doesn't suffice and you want name-based access to columns, you should consider setting row_factory to the highly optimized sqlite3.Row type. 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.

text_factory

A callable that accepts a bytes parameter and returns a text representation of it. The callable is invoked for SQLite values with the TEXT data type. By default, this attribute is set to str. If you want to return bytes instead, set text_factory to bytes.

例:

import sqlite3

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

AUSTRIA = "Österreich"

# by default, rows are returned as str
cur.execute("select ?", (AUSTRIA,))
row = cur.fetchone()
assert row[0] == AUSTRIA

# but we can make sqlite3 always return bytestrings ...
con.text_factory = bytes
cur.execute("select ?", (AUSTRIA,))
row = cur.fetchone()
assert type(row[0]) is bytes
# the bytestrings will be encoded in UTF-8, unless you stored garbage in the
# database ...
assert row[0] == AUSTRIA.encode("utf-8")

# we can also implement a custom text_factory ...
# here we implement one that appends "foo" to all strings
con.text_factory = lambda x: x.decode("utf-8") + "foo"
cur.execute("select ?", ("bar",))
row = cur.fetchone()
assert row[0] == "barfoo"

con.close()
total_changes

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

iterdump()

Return an iterator to dump the database as SQL source code. Useful when saving an in-memory database for later restoration. Similar to the .dump command in the sqlite3 shell.

以下はプログラム例です:

# 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()
backup(target, *, pages=- 1, progress=None, name='main', sleep=0.250)

Create a backup of an SQLite database.

Works even if the database is being accessed by other clients or concurrently by the same connection.

パラメータ
  • target (Connection) -- The database connection to save the backup to.

  • pages (int) -- The number of pages to copy at a time. If equal to or less than 0, the entire database is copied in a single step. Defaults to -1.

  • progress (callbackNone) -- If set to a callable, it is invoked with three integer arguments for every backup iteration: the status of the last iteration, the remaining number of pages still to be copied, and the total number of pages. Defaults to None.

  • name (str) -- The name of the database to back up. Either "main" (the default) for the main database, "temp" for the temporary database, or the name of a custom database as attached using the ATTACH DATABASE SQL statment.

  • sleep (float) -- The number of seconds to sleep between successive attempts to back up remaining pages.

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)

バージョン 3.7 で追加.

getlimit(category, /)

Get a connection runtime 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}")

バージョン 3.11 で追加.

setlimit(category, limit, /)

Set a connection runtime 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)

バージョン 3.11 で追加.

serialize(*, name='main')

Serialize a database into a 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.

注釈

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

バージョン 3.11 で追加.

deserialize(data, /, *, name='main')

Deserialize a serialized database into a Connection. 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 OperationalError if the database connection is currently involved in a read transaction or a backup operation. OverflowError will be raised if len(data) is larger than 2**63 - 1, and DatabaseError will be raised if data does not contain a valid SQLite database.

注釈

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

バージョン 3.11 で追加.

Cursor objects

A Cursor object represents a database cursor which is used to execute SQL statements, and manage the context of a fetch operation. Cursors are created using Connection.cursor(), or by using any of the connection shortcut methods.

Cursor objects are iterators, meaning that if you execute() a SELECT query, you can simply iterate over the cursor to fetch the resulting rows:

for row in cur.execute("select * from data"):
    print(row)
class sqlite3.Cursor

Cursor インスタンスは以下の属性やメソッドを持ちます。

execute(sql, parameters=(), /)

Execute SQL statement sql. Bind values to the statement using placeholders that map to the sequence or dict parameters.

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

If isolation_level is not None, sql is an INSERT, UPDATE, DELETE, or REPLACE statement, and there is no open transaction, a transaction is implicitly opened before executing sql.

executemany(sql, parameters, /)

Execute parameterized SQL statement sql against all parameter sequences or mappings found in the sequence parameters. It is also possible to use an iterator yielding parameters instead of a sequence. Uses the same implicit transaction handling as execute().

以下はプログラム例です:

data = [
    ("row1",),
    ("row2",),
]
# cur is an sqlite3.Cursor object
cur.executemany("insert into t values(?)", data)
executescript(sql_script, /)

Execute the SQL statements in sql_script. If there is a pending transaciton, an implicit COMMIT statement is executed first. No other implicit transaction control is performed; any transaction control must be added to sql_script.

sql_script must be a string.

以下はプログラム例です:

# cur is an sqlite3.Cursor object
cur.executescript("""
    begin;
    create table person(firstname, lastname, age);
    create table book(title, author, published);
    create table publisher(name, address);
    commit;
""")
fetchone()

Fetch the next row of a query result set as a tuple. Return None if no more data is available.

fetchmany(size=cursor.arraysize)

Fetch the next set of rows of a query result as a list. Return an empty list if no more rows are available.

The number of rows to fetch per call is specified by the size parameter. If size is not given, arraysize determines the number of rows to be fetched. If fewer than size rows are available, as many rows as are available are returned.

size 引数とパフォーマンスの関係についての注意です。パフォーマンスを最適化するためには、大抵、 arraysize 属性を利用するのがベストです。 size 引数を利用したのであれば、次の fetchmany() の呼び出しでも同じ数を利用するのがベストです。

fetchall()

Fetch all (remaining) rows of a query result as a list. Return an empty list if no rows are available. Note that the arraysize attribute can affect the performance of this operation.

close()

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

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

setinputsizes(sizes, /)

Required by the DB-API. Does nothing in sqlite3.

setoutputsize(size, column=None, /)

Required by the DB-API. Does nothing in sqlite3.

rowcount

Read-only attribute that provides the number of modified rows for INSERT, UPDATE, DELETE, and REPLACE statements; is -1 for other statements, including CTE queries. It is only updated by the execute() and executemany() methods.

lastrowid

Read-only attribute that provides the row id of the last inserted row. It is only updated after successful INSERT or REPLACE statements using the execute() method. For other statements, after executemany() or executescript(), or if the insertion failed, the value of lastrowid is left unchanged. The initial value of lastrowid is None.

注釈

Inserts into WITHOUT ROWID tables are not recorded.

バージョン 3.6 で変更: REPLACE 文のサポートが追加されました。

arraysize

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

description

Read-only attribute that 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 None.

この属性は SELECT 文にマッチする row が1つもなかった場合でもセットされます。

connection

Read-only attribute that provides the SQLite database Connection belonging to the cursor. A Cursor object created by calling con.cursor() will have a connection attribute that refers to con:

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

Row objects

class sqlite3.Row

A Row instance serves as a highly optimized row_factory for Connection objects. It tries to mimic a tuple in most of its features, and supports iteration, repr(), equality testing, len(), and mapping access by column name and index.

Two row objects compare equal if have equal columns and equal members.

keys()

Return a list of column names as strings. Immediately after a query, it is the first member of each tuple in Cursor.description.

バージョン 3.5 で変更: スライスがサポートされました。

Rowの例のために、まずサンプルのテーブルを初期化します:

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()

そして、 Row を使ってみます:

>>> 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

バージョン 3.11 で追加.

class sqlite3.Blob

A Blob instance is a file-like object that can read and write data in an SQLite BLOB. Call len(blob) to get the size (number of bytes) of the blob. Use indices and slices for direct access to the blob data.

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

import sqlite3

con = sqlite3.connect(":memory:")
con.execute("create table test(blob_col blob)")
con.execute("insert into test(blob_col) values (zeroblob(13))")

# Write to our blob, using two write operations:
with con.blobopen("test", "blob_col", 1) as blob:
    blob.write(b"hello, ")
    blob.write(b"world.")
    # Modify the first and last bytes of our blob
    blob[0] = ord("H")
    blob[-1] = ord("!")

# Read the contents of our blob
with con.blobopen("test", "blob_col", 1) as blob:
    greeting = blob.read()

print(greeting)  # outputs "b'Hello, world!'"
close()

Close the blob.

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

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 EOF will be returned. When length is not specified, or is negative, read() will read until the end of the blob.

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 ValueError.

tell()

Return the current access position of the blob.

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

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

PrepareProtocol objects

class sqlite3.PrepareProtocol

The PrepareProtocol type's single purpose is to act as a PEP 246 style adaption protocol for objects that can adapt themselves to native SQLite types.

例外

The exception hierarchy is defined by the DB-API 2.0 (PEP 249).

exception sqlite3.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 Exception.

exception sqlite3.Error

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

If the exception originated from within the SQLite library, the following two attributes are added to the exception:

sqlite_errorcode

The numeric error code from the SQLite API

バージョン 3.11 で追加.

sqlite_errorname

The symbolic name of the numeric error code from the SQLite API

バージョン 3.11 で追加.

exception sqlite3.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 Error.

exception sqlite3.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 Error.

exception sqlite3.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 DatabaseError.

exception sqlite3.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 DatabaseError.

exception sqlite3.IntegrityError

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

exception sqlite3.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 DatabaseError.

exception sqlite3.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 Connection. ProgrammingError is a subclass of DatabaseError.

exception sqlite3.NotSupportedError

Exception raised in case a method or database API is not supported by the underlying SQLite library. For example, setting deterministic to True in create_function(), if the underlying SQLite library does not support deterministic functions. NotSupportedError is a subclass of DatabaseError.

SQLite と Python の型

SQLite は以下の型をネイティブにサポートします: NULL, INTEGER, REAL, TEXT, BLOB

したがって、次の Python の型は問題なく SQLite に送り込めます:

Python の型

SQLite の型

None

NULL

int

INTEGER

float

REAL

str

TEXT

bytes

BLOB

SQLite の型から Python の型へのデフォルトでの変換は以下の通りです:

SQLite の型

Python の型

NULL

None

INTEGER

int

REAL

float

TEXT

text_factory に依存する。デフォルトでは str

BLOB

bytes

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

How-to guides

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 Python types SQLite natively understands.

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.

オブジェクト自身で適合するようにする

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 PrepareProtocol.

import sqlite3

class Point:
    def __init__(self, x, y):
        self.x, self.y = x, y

    def __conform__(self, protocol):
        if protocol is sqlite3.PrepareProtocol:
            return "%f;%f" % (self.x, self.y)

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

p = Point(4.0, -3.2)
cur.execute("select ?", (p,))
print(cur.fetchone()[0])

con.close()

適合関数を登録する

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 register_adapter().

import sqlite3

class Point:
    def __init__(self, x, y):
        self.x, self.y = x, y

def adapt_point(point):
    return "%f;%f" % (point.x, point.y)

sqlite3.register_adapter(Point, adapt_point)

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

p = Point(4.0, -3.2)
cur.execute("select ?", (p,))
print(cur.fetchone()[0])

con.close()

SQLite の値を好きな Python 型に変換する

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.

Point クラスの例に戻りましょう。x, y 座標をセミコロンで区切った文字列として SQLite に格納したのでした。

まず、文字列を引数として取り Point オブジェクトをそれから構築する変換関数を定義します。

注釈

Converter functions are always passed a 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 connect(). There are three options:

  • Implicit: set detect_types to PARSE_DECLTYPES

  • Explicit: set detect_types to PARSE_COLNAMES

  • Both: set detect_types to sqlite3.PARSE_DECLTYPES | sqlite3.PARSE_COLNAMES. Column names take precedence over declared types.

The following example illustrates the implicit and explicit approaches:

import sqlite3

class Point:
    def __init__(self, x, y):
        self.x, self.y = x, y

    def __repr__(self):
        return f"Point({self.x}, {self.y})"

def adapt_point(point):
    return f"{point.x};{point.y}".encode("utf-8")

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

# Register the adapter and converter
sqlite3.register_adapter(Point, adapt_point)
sqlite3.register_converter("point", convert_point)

# 1) Parse using declared types
p = Point(4.0, -3.2)
con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_DECLTYPES)
cur = con.execute("create table test(p point)")

cur.execute("insert into test(p) values (?)", (p,))
cur.execute("select p from test")
print("with declared types:", cur.fetchone()[0])
cur.close()
con.close()

# 2) Parse using column names
con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_COLNAMES)
cur = con.execute("create table test(p)")

cur.execute("insert into test(p) values (?)", (p,))
cur.execute('select p as "p [point]" from test')
print("with column names:", cur.fetchone()[0])
cur.close()
con.close()

デフォルトの適合関数と変換関数

datetime モジュールの date 型および datetime 型のためのデフォルト適合関数があります。これらの型は ISO 日付 / ISO タイムスタンプとして SQLite に送られます。

デフォルトの変換関数は datetime.date 用が "date" という名前で、 datetime.datetime 用が "timestamp" という名前で登録されています。

これにより、多くの場合特別な細工無しに Python の日付 / タイムスタンプを使えます。適合関数の書式は実験的な SQLite の date/time 関数とも互換性があります。

以下の例でこのことを確かめます。

import sqlite3
import datetime

con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_DECLTYPES|sqlite3.PARSE_COLNAMES)
cur = con.cursor()
cur.execute("create table test(d date, ts timestamp)")

today = datetime.date.today()
now = datetime.datetime.now()

cur.execute("insert into test(d, ts) values (?, ?)", (today, now))
cur.execute("select d, ts from test")
row = cur.fetchone()
print(today, "=>", row[0], type(row[0]))
print(now, "=>", row[1], type(row[1]))

cur.execute('select current_date as "d [date]", current_timestamp as "ts [timestamp]"')
row = cur.fetchone()
print("current_date", row[0], type(row[0]))
print("current_timestamp", row[1], type(row[1]))

con.close()

SQLite に格納されているタイムスタンプが6桁より長い小数部を持っている場合、タイムスタンプの変換関数によってマイクロ秒精度に丸められます。

注釈

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

Adapter and converter recipes

This section shows recipes for common adapters and converters.

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)

Using connection shortcut methods

Using the execute(), executemany(), and executescript() methods of the Connection class, your code can be written more concisely because you don't have to create the (often superfluous) Cursor objects explicitly. Instead, the 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 Connection object.

import sqlite3

langs = [
    ("C++", 1985),
    ("Objective-C", 1984),
]

con = sqlite3.connect(":memory:")

# Create the table
con.execute("create table lang(name, first_appeared)")

# Fill the table
con.executemany("insert into lang(name, first_appeared) values (?, ?)", langs)

# Print the table contents
for row in con.execute("select name, first_appeared from lang"):
    print(row)

print("I just deleted", con.execute("delete from lang").rowcount, "rows")

# close is not a shortcut method and it's not called automatically,
# so the connection object should be closed manually
con.close()

位置ではなく名前でカラムにアクセスする

sqlite3 モジュールの有用な機能の一つに、行生成関数として使われるための sqlite3.Row クラスがあります。

このクラスでラップされた行は、位置インデクス(タプルのような)でも大文字小文字を区別しない名前でもアクセスできます:

import sqlite3

con = sqlite3.connect(":memory:")
con.row_factory = sqlite3.Row

cur = con.cursor()
cur.execute("select 'John' as name, 42 as age")
for row in cur:
    assert row[0] == row["name"]
    assert row["name"] == row["nAmE"]
    assert row[1] == row["age"]
    assert row[1] == row["AgE"]

con.close()

コネクションをコンテキストマネージャーとして利用する

A 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 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.

注釈

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

import sqlite3

con = sqlite3.connect(":memory:")
con.execute("create table lang (id integer primary key, name varchar unique)")

# Successful, con.commit() is called automatically afterwards
with con:
    con.execute("insert into lang(name) values (?)", ("Python",))

# con.rollback() is called after the with block finishes with an exception, the
# exception is still raised and must be caught
try:
    with con:
        con.execute("insert into lang(name) values (?)", ("Python",))
except sqlite3.IntegrityError:
    print("couldn't add Python twice")

# Connection object used as context manager only commits or rollbacks transactions,
# so the connection object should be closed manually
con.close()

Working with SQLite URIs

Some useful URI tricks include:

  • Open a database in read-only mode:

    con = sqlite3.connect("file:template.db?mode=ro", uri=True)
    
  • Do not implicitly create a new database file if it does not already exist; will raise OperationalError if unable to create a new 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.execute("create table t(t)")
    con1.execute("insert into t values(28)")
    con1.commit()
    rows = con2.execute("select * from t").fetchall()
    

More information about this feature, including a list of parameters, can be found in the SQLite URI documentation.

Explanation

Transaction control

The sqlite3 module does not adhere to the transaction handling recommended by PEP 249.

If the connection attribute isolation_level is not None, new transactions are implicitly opened before execute() and executemany() executes INSERT, UPDATE, DELETE, or REPLACE statements. Use the commit() and rollback() methods to respectively commit and roll back pending transactions. You can choose the underlying SQLite transaction behaviour — that is, whether and what type of BEGIN statements sqlite3 implicitly executes – via the isolation_level attribute.

If isolation_level is set to None, no transactions are implicitly opened at all. This leaves the underlying SQLite library in autocommit mode, but also allows the user to perform their own transaction handling using explicit SQL statements. The underlying SQLite library autocommit mode can be queried using the in_transaction attribute.

The executescript() method implicitly commits any pending transaction before execution of the given SQL script, regardless of the value of isolation_level.

バージョン 3.6 で変更: sqlite3 used to implicitly commit an open transaction before DDL statements. This is no longer the case.