### 导航
- [索引](../genindex.xhtml "总目录")
- [模块](../py-modindex.xhtml "Python 模块索引") |
- [下一页](archiving.xhtml "数据压缩和存档") |
- [上一页](dbm.xhtml "dbm --- Interfaces to Unix "databases"") |
- ![](https://box.kancloud.cn/a721fc7ec672275e257bbbfde49a4d4e_16x16.png)
- [Python](https://www.python.org/) »
- zh\_CN 3.7.3 [文档](../index.xhtml) »
- [Python 标准库](index.xhtml) »
- [数据持久化](persistence.xhtml) »
- $('.inline-search').show(0); |
# [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") --- SQLite 数据库 DB-API 2.0 接口模块
**源代码:** [Lib/sqlite3/](https://github.com/python/cpython/tree/3.7/Lib/sqlite3/) \[https://github.com/python/cpython/tree/3.7/Lib/sqlite3/\]
- - - - - -
SQLite 是一个C语言库,它可以提供一种轻量级的基于磁盘的数据库,这种数据库不需要独立的服务器进程,也允许需要使用一种非标准的 SQL 查询语言来访问它。一些应用程序可以使用 SQLite 作为内部数据存储。可以用它来创建一个应用程序原型,然后再迁移到更大的数据库,比如 PostgreSQL 或 Oracle。
sqlite3 模块是由 Gerhard Häring 编写。它提供了符合 DB-API 2.0 规范的接口,这个规范是 [**PEP 249**](https://www.python.org/dev/peps/pep-0249) \[https://www.python.org/dev/peps/pep-0249\]。
要使用这个模块,必须先创建一个 [`Connection`](#sqlite3.Connection "sqlite3.Connection") 对象,它代表数据库。下面例子中,数据将存储在 `example.db` 文件中:
```
import sqlite3
conn = sqlite3.connect('example.db')
```
你也可以使用 `:memory:` 来创建一个内存中的数据库
当有了 [`Connection`](#sqlite3.Connection "sqlite3.Connection") 对象后,你可以创建一个 [`Cursor`](#sqlite3.Cursor "sqlite3.Cursor") 游标对象,然后调用它的 [`execute()`](#sqlite3.Cursor.execute "sqlite3.Cursor.execute") 方法来执行 SQL 语句:
```
c = conn.cursor()
# Create table
c.execute('''CREATE TABLE stocks
(date text, trans text, symbol text, qty real, price real)''')
# Insert a row of data
c.execute("INSERT INTO stocks VALUES ('2006-01-05','BUY','RHAT',100,35.14)")
# Save (commit) the changes
conn.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.
conn.close()
```
这些数据被持久化保存了,而且可以在之后的会话中使用它们:
```
import sqlite3
conn = sqlite3.connect('example.db')
c = conn.cursor()
```
通常你的 SQL 操作需要使用一些 Python 变量的值。你不应该使用 Python 的字符串操作来创建你的查询语句,因为那样做不安全;它会使你的程序容易受到 SQL 注入攻击(在 <https://xkcd.com/327/> 上有一个搞笑的例子,看看有什么后果)
推荐另外一种方法:使用 DB-API 的参数替换。在你的 SQL 语句中,使用 `?` 占位符来代替值,然后把对应的值组成的元组做为 [`execute()`](#sqlite3.Cursor.execute "sqlite3.Cursor.execute") 方法的第二个参数。(其他数据库可能会使用不同的占位符,比如 `%s` 或者 `:1`)例如:
```
# Never do this -- insecure!
symbol = 'RHAT'
c.execute("SELECT * FROM stocks WHERE symbol = '%s'" % symbol)
# Do this instead
t = ('RHAT',)
c.execute('SELECT * FROM stocks WHERE symbol=?', t)
print(c.fetchone())
# Larger example that inserts many records at a time
purchases = [('2006-03-28', 'BUY', 'IBM', 1000, 45.00),
('2006-04-05', 'BUY', 'MSFT', 1000, 72.00),
('2006-04-06', 'SELL', 'IBM', 500, 53.00),
]
c.executemany('INSERT INTO stocks VALUES (?,?,?,?,?)', purchases)
```
要在执行 SELECT 语句后获取数据,你可以把游标作为 [iterator](../glossary.xhtml#term-iterator),然后调用它的 [`fetchone()`](#sqlite3.Cursor.fetchone "sqlite3.Cursor.fetchone") 方法来获取一条匹配的行,也可以调用 [`fetchall()`](#sqlite3.Cursor.fetchall "sqlite3.Cursor.fetchall") 来得到包含多个匹配行的列表。
下面是一个使用迭代器形式的例子:
```
>>> for row in c.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)
```
参见
<https://github.com/ghaering/pysqlite>pysqlite的主页 -- sqlite3 在外部使用 “pysqlite” 名字进行开发。
<https://www.sqlite.org>SQLite的主页;它的文档详细描述了它所支持的 SQL 方言的语法和可用的数据类型。
<https://www.w3schools.com/sql/>学习 SQL 语法的教程、参考和例子。
[**PEP 249**](https://www.python.org/dev/peps/pep-0249) \[https://www.python.org/dev/peps/pep-0249\] - DB-API 2.0 规范Marc-André Lemburg 写的 PEP。
## 模块函数和常量
`sqlite3.``version`这个模块的版本号,是一个字符串。不是 SQLite 库的版本号。
`sqlite3.``version_info`这个模块的版本号,是一个由整数组成的元组。不是 SQLite 库的版本号。
`sqlite3.``sqlite_version`使用中的 SQLite 库的版本号,是一个字符串。
`sqlite3.``sqlite_version_info`使用中的 SQLite 库的版本号,是一个整数组成的元组。
`sqlite3.``PARSE_DECLTYPES`这个常量可以作为 [`connect()`](#sqlite3.connect "sqlite3.connect") 函数的 *detect\_types* 参数。
设置这个参数后,[`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") 模块将解析它返回的每一列申明的类型。它会申明的类型的第一个单词,比如“integer primary key”,它会解析出“integer”,再比如“number(10)”,它会解析出“number”。然后,它会在转换器字典里查找那个类型注册的转换器函数,并调用它。
`sqlite3.``PARSE_COLNAMES`这个常量可以作为 [`connect()`](#sqlite3.connect "sqlite3.connect") 函数的 *detect\_types* 参数。
设置这个参数后,SQLite 接口将解析它返回的每一列的列名。它会在其中查找 \[mytype\] 这个形式的字符串,然后用‘mytype’来决定那个列的类型。它会尝试在转换器字典中查找‘mytype’键对应的转换器函数,然后用这个转换器函数返回的值来做为列的类型。在 [`Cursor.description`](#sqlite3.Cursor.description "sqlite3.Cursor.description") 中找到的列名仅仅是列名的第一个单词,比如你在 SQL 中使用 `'as "x [datetime]"'`,然后它会解析出第一个空白字符前的所有字符来作为列名:列名就是“x”。
`sqlite3.``connect`(*database*\[, *timeout*, *detect\_types*, *isolation\_level*, *check\_same\_thread*, *factory*, *cached\_statements*, *uri*\])连接 SQLite 数据库 *database*。默认返回 [`Connection`](#sqlite3.Connection "sqlite3.Connection") 对象,除非使用了自定义的 *factory* 参数。
*database* 是准备打开的数据库文件的路径(绝对路径或相对于当前目录的相对路径),它是 [path-like object](../glossary.xhtml#term-path-like-object)。你也可以用 `":memory:"` 在内存中打开一个数据库。
当一个数据库被多个连接访问的时候,如果其中一个进程修改这个数据库,在这个事务提交之前,这个 SQLite 数据库将会被一直锁定。*timeout* 参数指定了这个连接等待锁释放的超时时间,超时之后会引发一个异常。这个超时时间默认是 5.0(5秒)。
*isolation\_level* 参数,请查看 [`Connection`](#sqlite3.Connection "sqlite3.Connection") 对象的 [`isolation_level`](#sqlite3.Connection.isolation_level "sqlite3.Connection.isolation_level") 属性。
SQLite 原生只支持5种类型:TEXT,INTEGER,REAL,BLOB 和 NULL。如果你想用其它类型,你必须自己添加相应的支持。使用 *detect\_types* 参数和模块级别的 [`register_converter()`](#sqlite3.register_converter "sqlite3.register_converter") 函数注册\*\*转换器\*\* 可以简单的实现。
*detect\_types* 默认为0(即关闭,没有类型检测)。你也可以组合 [`PARSE_DECLTYPES`](#sqlite3.PARSE_DECLTYPES "sqlite3.PARSE_DECLTYPES") 和 [`PARSE_COLNAMES`](#sqlite3.PARSE_COLNAMES "sqlite3.PARSE_COLNAMES") 来开启类型检测。
默认情况下,*check\_same\_thread* 为 [`True`](constants.xhtml#True "True"),只有当前的线程可以使用该连接。 如果设置为 [`False`](constants.xhtml#False "False"),则多个线程可以共享返回的连接。 当多个线程使用同一个连接的时候,用户应该把写操作进行序列化,以避免数据损坏。
默认情况下,当调用 connect 方法的时候,[`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") 模块使用了它的 [`Connection`](#sqlite3.Connection "sqlite3.Connection") 类。当然,你也可以创建 [`Connection`](#sqlite3.Connection "sqlite3.Connection") 类的子类,然后创建提供了 *factory* 参数的 [`connect()`](#sqlite3.connect "sqlite3.connect") 方法。
详情请查阅当前手册的 [SQLite 与 Python 类型](#sqlite3-types) 部分。
[`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") 模块在内部使用语句缓存来避免 SQL 解析开销。 如果要显式设置当前连接可以缓存的语句数,可以设置 *cached\_statements* 参数。 当前实现的默认值是缓存100条语句。
如果 *uri* 为真,则 *database* 被解释为 URI。 它允许您指定选项。 例如,以只读模式打开数据库:
```
db = sqlite3.connect('file:path/to/database?mode=ro', uri=True)
```
有关此功能的更多信息,包括已知选项的列表,可以在 ` SQLite URI 文档 <<https://www.sqlite.org/uri.html>>`\_ 中找到。
在 3.4 版更改: 增加了 *uri* 参数。
在 3.7 版更改: *database* 现在可以是一个 [path-like object](../glossary.xhtml#term-path-like-object) 对象了,不仅仅是字符串。
`sqlite3.``register_converter`(*typename*, *callable*)注册一个回调对象 *callable*, 用来转换数据库中的字节串为自定的 Python 类型。所有类型为 *typename* 的数据库的值在转换时,都会调用这个回调对象。通过指定 [`connect()`](#sqlite3.connect "sqlite3.connect") 函数的 *detect-types* 参数来设置类型检测的方式。注意,*typename* 与查询语句中的类型名进行匹配时不区分大小写。
`sqlite3.``register_adapter`(*type*, *callable*)注册一个回调对象 *callable*,用来转换自定义Python类型为一个 SQLite 支持的类型。 这个回调对象 *callable* 仅接受一个 Python 值作为参数,而且必须返回以下某个类型的值:int,float,str 或 bytes。
`sqlite3.``complete_statement`(*sql*)如果字符串 *sql* 包含一个或多个完整的 SQL 语句(以分号结束)则返回 [`True`](constants.xhtml#True "True")。它不会验证 SQL 语法是否正确,仅会验证字符串字面上是否完整,以及是否以分号结束。
它可以用来构建一个 SQLite shell,下面是一个例子:
```
# 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:
print("An error occurred:", e.args[0])
buffer = ""
con.close()
```
`sqlite3.``enable_callback_tracebacks`(*flag*)默认情况下,您不会获得任何用户定义函数中的回溯消息,比如聚合,转换器,授权器回调等。如果要调试它们,可以设置 *flag* 参数为 `True` 并调用此函数。 之后,回调中的回溯信息将会输出到 `sys.stderr`。 再次使用 [`False`](constants.xhtml#False "False") 来禁用该功能。
## 连接对象(Connection)
*class* `sqlite3.``Connection`SQLite 数据库连接对象有如下的属性和方法:
`isolation_level`获取或设置当前默认的隔离级别。 表示自动提交模式的 [`None`](constants.xhtml#None "None") 以及 "DEFERRED", "IMMEDIATE" 或 "EXCLUSIVE" 其中之一。 详细描述请参阅 [Controlling Transactions](#sqlite3-controlling-transactions)。
`in_transaction`如果是在活动事务中(还没有提交改变),返回 [`True`](constants.xhtml#True "True"),否则,返回 [`False`](constants.xhtml#False "False")。它是一个只读属性。
3\.2 新版功能.
`cursor`(*factory=Cursor*)这个方法接受一个可选参数 *factory*,如果要指定这个参数,它必须是一个可调用对象,而且必须返回 [`Cursor`](#sqlite3.Cursor "sqlite3.Cursor") 类的一个实例或者子类。
`commit`()这个方法提交当前事务。如果没有调用这个方法,那么从上一次提交 `commit()` 以来所有的变化在其他数据库连接上都是不可见的。如果你往数据库里写了数据,但是又查询不到,请检查是否忘记了调用这个方法。
`rollback`()这个方法回滚从上一次调用 [`commit()`](#sqlite3.Connection.commit "sqlite3.Connection.commit") 以来所有数据库的改变。
`close`()关闭数据库连接。注意,它不会自动调用 [`commit()`](#sqlite3.Connection.commit "sqlite3.Connection.commit") 方法。如果在关闭数据库连接之前没有调用 [`commit()`](#sqlite3.Connection.commit "sqlite3.Connection.commit"),那么你的修改将会丢失!
`execute`(*sql*\[, *parameters*\])这是一个非标准的快捷方法,它会调用 [`cursor()`](#sqlite3.Connection.cursor "sqlite3.Connection.cursor") 方法来创建一个游标对象,并使用给定的 *parameters* 参数来调用游标对象的 [`execute()`](#sqlite3.Cursor.execute "sqlite3.Cursor.execute") 方法,最后返回这个游标对象。
`executemany`(*sql*\[, *parameters*\])这是一个非标准的快捷方法,它会调用 [`cursor()`](#sqlite3.Connection.cursor "sqlite3.Connection.cursor") 方法来创建一个游标对象,并使用给定的 *parameters* 参数来调用游标对象的 [`executemany()`](#sqlite3.Cursor.executemany "sqlite3.Cursor.executemany") 方法,最后返回这个游标对象。
`executescript`(*sql\_script*)这是一个非标准的快捷方法,它会调用 [`cursor()`](#sqlite3.Connection.cursor "sqlite3.Connection.cursor") 方法来创建一个游标对象,并使用给定的 *sql\_script* 参数来调用游标对象的 [`executescript()`](#sqlite3.Cursor.executescript "sqlite3.Cursor.executescript") 方法,最后返回这个游标对象。
`create_function`(*name*, *num\_params*, *func*)创建一个可以在 SQL 语句中使用的自定义函数,其中参数 *name* 为 SQL 语句中使用的函数名,*num\_params* 是这个函数接受的参数个数(如果 *num\_params* 为 -1,那这个函数可以接受任意数量的参数),最后一个参数 *func* 是作为 SQL 函数调用的一个 Python 可调用对象。
此函数可返回任何 SQLite 所支持的类型: bytes, str, int, float 和 `None`。
示例:
```
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*, *num\_params*, *aggregate\_class*)创建一个自定义的聚合函数。
参数中 *aggregate\_class* 类必须实现两个方法:`step` 和 `finalize`。`step` 方法接受 *num\_params* 个参数(如果 *num\_params* 为 -1,那么这个函数可以接受任意数量的参数);`finalize` 方法返回最终的聚合结果。
`finalize` 方法可以返回任何 SQLite 支持的类型:bytes,str,int,float 和 `None`。
示例:
```
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_collation`(*name*, *callable*)使用 *name* 和 *callable* 创建排序规则。这个 *callable* 接受两个字符串对象,如果第一个小于第二个则返回 -1, 如果两个相等则返回 0,如果第一个大于第二个则返回 1。注意,这是用来控制排序的(SQL 中的 ORDER BY),所以它不会影响其它的 SQL 操作。
注意,这个 *callable* 可调用对象会把它的参数作为 Python 字节串,通常会以 UTF-8 编码格式对它进行编码。
The following example shows a custom collation that sorts "the wrong way":
```
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()
```
要移除一个排序规则,需要调用 `create_collation` 并设置 callable 参数为 `None`。
```
con.create_collation("reverse", None)
```
`interrupt`()可以从不同的线程调用这个方法来终止所有查询操作,这些查询操作可能正在连接上执行。此方法调用之后, 查询将会终止,而且查询的调用者会获得一个异常。
`set_authorizer`(*authorizer\_callback*)此方法注册一个授权回调对象。每次在访问数据库中某个表的某一列的时候,这个回调对象将会被调用。如果要允许访问,则返回 `SQLITE_OK`,如果要终止整个 SQL 语句,则返回 `SQLITE_DENY`,如果这一列需要当做 NULL 值处理,则返回 `SQLITE_IGNORE`。这些常量可以在 [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") 模块中找到。
The first argument to the callback signifies what kind of operation is to be authorized. The second and third argument will be arguments or [`None`](constants.xhtml#None "None")depending on the first argument. The 4th argument is the name of the database ("main", "temp", etc.) if applicable. The 5th argument is the name of the inner-most trigger or view that is responsible for the access attempt or [`None`](constants.xhtml#None "None") if this access attempt is directly from input SQL code.
Please consult the SQLite documentation about the possible values for the first argument and the meaning of the second and third argument depending on the first one. All necessary constants are available in the [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module.
`set_progress_handler`(*handler*, *n*)This routine registers a callback. The callback is invoked for every *n*instructions of the SQLite virtual machine. This is useful if you want to get called from SQLite during long-running operations, for example to update a GUI.
If you want to clear any previously installed progress handler, call the method with [`None`](constants.xhtml#None "None") for *handler*.
Returning a non-zero value from the handler function will terminate the currently executing query and cause it to raise an [`OperationalError`](#sqlite3.OperationalError "sqlite3.OperationalError")exception.
`set_trace_callback`(*trace\_callback*)Registers *trace\_callback* to be called for each SQL statement that is actually executed by the SQLite backend.
The only argument passed to the callback is the statement (as string) 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()`](#sqlite3.Cursor.execute "sqlite3.Cursor.execute")methods. Other sources include the transaction management of the Python module and the execution of triggers defined in the current database.
Passing [`None`](constants.xhtml#None "None") as *trace\_callback* will disable the trace callback.
3\.3 新版功能.
`enable_load_extension`(*enabled*)This routine allows/disallows the SQLite engine to load SQLite extensions from shared libraries. SQLite extensions can define new functions, aggregates or whole new virtual table implementations. One well-known extension is the fulltext-search extension distributed with SQLite.
Loadable extensions are disabled by default. See [1](#f1).
3\.2 新版功能.
```
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*)This routine loads a SQLite extension from a shared library. You have to enable extension loading with [`enable_load_extension()`](#sqlite3.Connection.enable_load_extension "sqlite3.Connection.enable_load_extension") before you can use this routine.
Loadable extensions are disabled by default. See [1](#f1).
3\.2 新版功能.
`row_factory`You can change this attribute to a callable that accepts the cursor and the original row as a tuple and will return the real result row. This way, you can implement more advanced ways of returning results, such as returning an object that can also access columns by name.
示例:
```
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`](#sqlite3.Connection.row_factory "sqlite3.Connection.row_factory") to the highly-optimized [`sqlite3.Row`](#sqlite3.Row "sqlite3.Row") type. [`Row`](#sqlite3.Row "sqlite3.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`Using this attribute you can control what objects are returned for the `TEXT`data type. By default, this attribute is set to [`str`](stdtypes.xhtml#str "str") and the [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module will return Unicode objects for `TEXT`. If you want to return bytestrings instead, you can set it to [`bytes`](stdtypes.xhtml#bytes "bytes").
You can also set it to any other callable that accepts a single bytestring parameter and returns the resulting object.
See the following example code for illustration:
```
import sqlite3
con = sqlite3.connect(":memory:")
cur = con.cursor()
AUSTRIA = "\xd6sterreich"
# by default, rows are returned as Unicode
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`Returns the total number of database rows that have been modified, inserted, or deleted since the database connection was opened.
`iterdump`()Returns an iterator to dump the database in an SQL text format. Useful when saving an in-memory database for later restoration. This function provides the same capabilities as the .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=0*, *progress=None*, *name="main"*, *sleep=0.250*)This method makes a backup of a SQLite database even while it's being accessed by other clients, or concurrently by the same connection. The copy will be written into the mandatory argument *target*, that must be another [`Connection`](#sqlite3.Connection "sqlite3.Connection") instance.
By default, or when *pages* is either `0` or a negative integer, the entire database is copied in a single step; otherwise the method performs a loop copying up to *pages* pages at a time.
If *progress* is specified, it must either be `None` or a callable object that will be executed at each iteration with three integer arguments, respectively the *status* of the last iteration, the *remaining* number of pages still to be copied and the *total* number of pages.
The *name* argument specifies the database name that will be copied: it must be a string containing either `"main"`, the default, to indicate the main database, `"temp"` to indicate the temporary database or the name specified after the `AS` keyword in an `ATTACH DATABASE` statement for an attached database.
The *sleep* argument specifies the number of seconds to sleep by between successive attempts to backup remaining pages, can be specified either as an integer or a floating point value.
示例一,将现有数据库复制到另一个数据库中:
```
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()
```
示例二,将现有数据库复制到临时副本中:
```
import sqlite3
source = sqlite3.connect('existing_db.db')
dest = sqlite3.connect(':memory:')
source.backup(dest)
```
可用性:SQLite 3.6.11 或以上版本
3\.7 新版功能.
## 游标对象\*Cursor\*
*class* `sqlite3.``Cursor`[`Cursor`](#sqlite3.Cursor "sqlite3.Cursor") 游标实例具有以下属性和方法。
`execute`(*sql*\[, *parameters*\])执行SQL语句。 可以是参数化 SQL 语句(即,在 SQL 语句中使用占位符)。[`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") 模块支持两种占位符:问号(qmark风格)和命名占位符(命名风格)。
以下是两种风格的示例:
```
import sqlite3
con = sqlite3.connect(":memory:")
cur = con.cursor()
cur.execute("create table people (name_last, age)")
who = "Yeltsin"
age = 72
# This is the qmark style:
cur.execute("insert into people values (?, ?)", (who, age))
# And this is the named style:
cur.execute("select * from people where name_last=:who and age=:age", {"who": who, "age": age})
print(cur.fetchone())
con.close()
```
[`execute()`](#sqlite3.Cursor.execute "sqlite3.Cursor.execute") will only execute a single SQL statement. If you try to execute more than one statement with it, it will raise a [`Warning`](#sqlite3.Warning "sqlite3.Warning"). Use [`executescript()`](#sqlite3.Cursor.executescript "sqlite3.Cursor.executescript") if you want to execute multiple SQL statements with one call.
`executemany`(*sql*, *seq\_of\_parameters*)Executes an SQL command against all parameter sequences or mappings found in the sequence *seq\_of\_parameters*. The [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module also allows using an [iterator](../glossary.xhtml#term-iterator) yielding parameters instead of a sequence.
```
import sqlite3
class IterChars:
def __init__(self):
self.count = ord('a')
def __iter__(self):
return self
def __next__(self):
if self.count > ord('z'):
raise StopIteration
self.count += 1
return (chr(self.count - 1),) # this is a 1-tuple
con = sqlite3.connect(":memory:")
cur = con.cursor()
cur.execute("create table characters(c)")
theIter = IterChars()
cur.executemany("insert into characters(c) values (?)", theIter)
cur.execute("select c from characters")
print(cur.fetchall())
con.close()
```
这是一个使用生成器 [generator](../glossary.xhtml#term-generator) 的简短示例:
```
import sqlite3
import string
def char_generator():
for c in string.ascii_lowercase:
yield (c,)
con = sqlite3.connect(":memory:")
cur = con.cursor()
cur.execute("create table characters(c)")
cur.executemany("insert into characters(c) values (?)", char_generator())
cur.execute("select c from characters")
print(cur.fetchall())
con.close()
```
`executescript`(*sql\_script*)This is a nonstandard convenience method for executing multiple SQL statements at once. It issues a `COMMIT` statement first, then executes the SQL script it gets as a parameter.
*sql\_script* can be an instance of [`str`](stdtypes.xhtml#str "str").
示例:
```
import sqlite3
con = sqlite3.connect(":memory:")
cur = con.cursor()
cur.executescript("""
create table person(
firstname,
lastname,
age
);
create table book(
title,
author,
published
);
insert into book(title, author, published)
values (
'Dirk Gently''s Holistic Detective Agency',
'Douglas Adams',
1987
);
""")
con.close()
```
`fetchone`()Fetches the next row of a query result set, returning a single sequence, or [`None`](constants.xhtml#None "None") when no more data is available.
`fetchmany`(*size=cursor.arraysize*)Fetches the next set of rows of a query result, returning a list. An empty list is returned when no more rows are available.
The number of rows to fetch per call is specified by the *size* parameter. If it is not given, the cursor's arraysize determines the number of rows to be fetched. The method should try to fetch as many rows as indicated by the size parameter. If this is not possible due to the specified number of rows not being available, fewer rows may be returned.
Note there are performance considerations involved with the *size* parameter. For optimal performance, it is usually best to use the arraysize attribute. If the *size* parameter is used, then it is best for it to retain the same value from one [`fetchmany()`](#sqlite3.Cursor.fetchmany "sqlite3.Cursor.fetchmany") call to the next.
`fetchall`()Fetches all (remaining) rows of a query result, returning a list. Note that the cursor's arraysize attribute can affect the performance of this operation. An empty list is returned when no rows are available.
`close`()Close the cursor now (rather than whenever `__del__` is called).
The cursor will be unusable from this point forward; a [`ProgrammingError`](#sqlite3.ProgrammingError "sqlite3.ProgrammingError")exception will be raised if any operation is attempted with the cursor.
`rowcount`Although the [`Cursor`](#sqlite3.Cursor "sqlite3.Cursor") class of the [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module implements this attribute, the database engine's own support for the determination of "rows affected"/"rows selected" is quirky.
For [`executemany()`](#sqlite3.Cursor.executemany "sqlite3.Cursor.executemany") statements, the number of modifications are summed up into [`rowcount`](#sqlite3.Cursor.rowcount "sqlite3.Cursor.rowcount").
As required by the Python DB API Spec, the [`rowcount`](#sqlite3.Cursor.rowcount "sqlite3.Cursor.rowcount") attribute "is -1 in case no `executeXX()` has been performed on the cursor or the rowcount of the last operation is not determinable by the interface". This includes `SELECT`statements because we cannot determine the number of rows a query produced until all rows were fetched.
With SQLite versions before 3.6.5, [`rowcount`](#sqlite3.Cursor.rowcount "sqlite3.Cursor.rowcount") is set to 0 if you make a `DELETE FROM table` without any condition.
`lastrowid`This read-only attribute provides the rowid of the last modified row. It is only set if you issued an `INSERT` or a `REPLACE` statement using the [`execute()`](#sqlite3.Cursor.execute "sqlite3.Cursor.execute") method. For operations other than `INSERT` or `REPLACE` or when [`executemany()`](#sqlite3.Cursor.executemany "sqlite3.Cursor.executemany") is called, [`lastrowid`](#sqlite3.Cursor.lastrowid "sqlite3.Cursor.lastrowid") is set to [`None`](constants.xhtml#None "None").
If the `INSERT` or `REPLACE` statement failed to insert the previous successful rowid is returned.
在 3.6 版更改: 增加了 `REPLACE` 语句的支持。
`arraysize`Read/write attribute that controls the number of rows returned by [`fetchmany()`](#sqlite3.Cursor.fetchmany "sqlite3.Cursor.fetchmany"). The default value is 1 which means a single row would be fetched per call.
`description`This read-only attribute provides the column names of the last query. To remain compatible with the Python DB API, it returns a 7-tuple for each column where the last six items of each tuple are [`None`](constants.xhtml#None "None").
It is set for `SELECT` statements without any matching rows as well.
`connection`This read-only attribute provides the SQLite database [`Connection`](#sqlite3.Connection "sqlite3.Connection")used by the [`Cursor`](#sqlite3.Cursor "sqlite3.Cursor") object. A [`Cursor`](#sqlite3.Cursor "sqlite3.Cursor") object created by calling [`con.cursor()`](#sqlite3.Connection.cursor "sqlite3.Connection.cursor") will have a [`connection`](#sqlite3.Cursor.connection "sqlite3.Cursor.connection") attribute that refers to *con*:
```
>>> con = sqlite3.connect(":memory:")
>>> cur = con.cursor()
>>> cur.connection == con
True
```
## 行对象\*Row\*
*class* `sqlite3.``Row`A [`Row`](#sqlite3.Row "sqlite3.Row") instance serves as a highly optimized [`row_factory`](#sqlite3.Connection.row_factory "sqlite3.Connection.row_factory") for [`Connection`](#sqlite3.Connection "sqlite3.Connection") objects. It tries to mimic a tuple in most of its features.
It supports mapping access by column name and index, iteration, representation, equality testing and [`len()`](functions.xhtml#len "len").
If two [`Row`](#sqlite3.Row "sqlite3.Row") objects have exactly the same columns and their members are equal, they compare equal.
`keys`()This method returns a list of column names. Immediately after a query, it is the first member of each tuple in [`Cursor.description`](#sqlite3.Cursor.description "sqlite3.Cursor.description").
在 3.5 版更改: Added support of slicing.
Let's assume we initialize a table as in the example given above:
```
conn = sqlite3.connect(":memory:")
c = conn.cursor()
c.execute('''create table stocks
(date text, trans text, symbol text,
qty real, price real)''')
c.execute("""insert into stocks
values ('2006-01-05','BUY','RHAT',100,35.14)""")
conn.commit()
c.close()
```
Now we plug [`Row`](#sqlite3.Row "sqlite3.Row") in:
```
>>> conn.row_factory = sqlite3.Row
>>> c = conn.cursor()
>>> c.execute('select * from stocks')
<sqlite3.Cursor object at 0x7f4e7dd8fa80>
>>> r = c.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
```
## 异常
*exception* `sqlite3.``Warning`[`Exception`](exceptions.xhtml#Exception "Exception") 的一个子类。
*exception* `sqlite3.``Error`此模块中其他异常的基类。 它是 [`Exception`](exceptions.xhtml#Exception "Exception") 的一个子类。
*exception* `sqlite3.``DatabaseError`Exception raised for errors that are related to the database.
*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`](#sqlite3.DatabaseError "sqlite3.DatabaseError").
*exception* `sqlite3.``ProgrammingError`Exception raised for programming errors, e.g. table not found or already exists, syntax error in the SQL statement, wrong number of parameters specified, etc. It is a subclass of [`DatabaseError`](#sqlite3.DatabaseError "sqlite3.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, e.g. an unexpected disconnect occurs, the data source name is not found, a transaction could not be processed, etc. It is a subclass of [`DatabaseError`](#sqlite3.DatabaseError "sqlite3.DatabaseError").
*exception* `sqlite3.``NotSupportedError`Exception raised in case a method or database API was used which is not supported by the database, e.g. calling the [`rollback()`](#sqlite3.Connection.rollback "sqlite3.Connection.rollback")method on a connection that does not support transaction or has transactions turned off. It is a subclass of [`DatabaseError`](#sqlite3.DatabaseError "sqlite3.DatabaseError").
## SQLite 与 Python 类型
### 概述
SQLite 原生支持如下的类型: `NULL`,`INTEGER`,`REAL`,`TEXT`,`BLOB`。
The following Python types can thus be sent to SQLite without any problem:
Python 类型
SQLite 类型
[`None`](constants.xhtml#None "None")
`NULL`
[`int`](functions.xhtml#int "int")
`INTEGER`
[`float`](functions.xhtml#float "float")
`REAL`
[`str`](stdtypes.xhtml#str "str")
`TEXT`
[`bytes`](stdtypes.xhtml#bytes "bytes")
`BLOB`
This is how SQLite types are converted to Python types by default:
SQLite 类型
Python 类型
`NULL`
[`None`](constants.xhtml#None "None")
`INTEGER`
[`int`](functions.xhtml#int "int")
`REAL`
[`float`](functions.xhtml#float "float")
`TEXT`
depends on [`text_factory`](#sqlite3.Connection.text_factory "sqlite3.Connection.text_factory"), [`str`](stdtypes.xhtml#str "str") by default
`BLOB`
[`bytes`](stdtypes.xhtml#bytes "bytes")
The type system of the [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module is extensible in two ways: you can store additional Python types in a SQLite database via object adaptation, and you can let the [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module convert SQLite types to different Python types via converters.
### Using adapters to store additional Python types in SQLite databases
As described before, SQLite supports only a limited set of types natively. To use other Python types with SQLite, you must **adapt** them to one of the sqlite3 module's supported types for SQLite: one of NoneType, int, float, str, bytes.
There are two ways to enable the [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module to adapt a custom Python type to one of the supported ones.
#### Letting your object adapt itself
This is a good approach if you write the class yourself. Let's suppose you have a class like this:
```
class Point:
def __init__(self, x, y):
self.x, self.y = x, y
```
Now you want to store the point in a single SQLite column. First you'll have to choose one of the supported types first to be used for representing the point. Let's just use str and separate the coordinates using a semicolon. Then you need to give your class a method `__conform__(self, protocol)` which must return the converted value. The parameter *protocol* will be `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()
```
#### Registering an adapter callable
The other possibility is to create a function that converts the type to the string representation and register the function with [`register_adapter()`](#sqlite3.register_adapter "sqlite3.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()
```
The [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module has two default adapters for Python's built-in [`datetime.date`](datetime.xhtml#datetime.date "datetime.date") and [`datetime.datetime`](datetime.xhtml#datetime.datetime "datetime.datetime") types. Now let's suppose we want to store [`datetime.datetime`](datetime.xhtml#datetime.datetime "datetime.datetime") objects not in ISO representation, but as a Unix timestamp.
```
import sqlite3
import datetime
import time
def adapt_datetime(ts):
return time.mktime(ts.timetuple())
sqlite3.register_adapter(datetime.datetime, adapt_datetime)
con = sqlite3.connect(":memory:")
cur = con.cursor()
now = datetime.datetime.now()
cur.execute("select ?", (now,))
print(cur.fetchone()[0])
con.close()
```
### Converting SQLite values to custom Python types
Writing an adapter lets you send custom Python types to SQLite. But to make it really useful we need to make the Python to SQLite to Python roundtrip work.
Enter converters.
Let's go back to the `Point` class. We stored the x and y coordinates separated via semicolons as strings in SQLite.
First, we'll define a converter function that accepts the string as a parameter and constructs a `Point` object from it.
注解
Converter functions **always** get called with a [`bytes`](stdtypes.xhtml#bytes "bytes") object, no matter under which data type you sent the value to SQLite.
```
def convert_point(s):
x, y = map(float, s.split(b";"))
return Point(x, y)
```
Now you need to make the [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module know that what you select from the database is actually a point. There are two ways of doing this:
- Implicitly via the declared type
- Explicitly via the column name
Both ways are described in section [模块函数和常量](#sqlite3-module-contents), in the entries for the constants [`PARSE_DECLTYPES`](#sqlite3.PARSE_DECLTYPES "sqlite3.PARSE_DECLTYPES") and [`PARSE_COLNAMES`](#sqlite3.PARSE_COLNAMES "sqlite3.PARSE_COLNAMES").
The following example illustrates both approaches.
```
import sqlite3
class Point:
def __init__(self, x, y):
self.x, self.y = x, y
def __repr__(self):
return "(%f;%f)" % (self.x, self.y)
def adapt_point(point):
return ("%f;%f" % (point.x, point.y)).encode('ascii')
def convert_point(s):
x, y = list(map(float, s.split(b";")))
return Point(x, y)
# Register the adapter
sqlite3.register_adapter(Point, adapt_point)
# Register the converter
sqlite3.register_converter("point", convert_point)
p = Point(4.0, -3.2)
#########################
# 1) Using declared types
con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_DECLTYPES)
cur = con.cursor()
cur.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()
#######################
# 1) Using column names
con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_COLNAMES)
cur = con.cursor()
cur.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()
```
### Default adapters and converters
There are default adapters for the date and datetime types in the datetime module. They will be sent as ISO dates/ISO timestamps to SQLite.
The default converters are registered under the name "date" for [`datetime.date`](datetime.xhtml#datetime.date "datetime.date") and under the name "timestamp" for [`datetime.datetime`](datetime.xhtml#datetime.datetime "datetime.datetime").
This way, you can use date/timestamps from Python without any additional fiddling in most cases. The format of the adapters is also compatible with the experimental SQLite date/time functions.
The following example demonstrates this.
```
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()
```
If a timestamp stored in SQLite has a fractional part longer than 6 numbers, its value will be truncated to microsecond precision by the timestamp converter.
## Controlling Transactions
The underlying `sqlite3` library operates in `autocommit` mode by default, but the Python [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module by default does not.
`autocommit` mode means that statements that modify the database take effect immediately. A `BEGIN` or `SAVEPOINT` statement disables `autocommit`mode, and a `COMMIT`, a `ROLLBACK`, or a `RELEASE` that ends the outermost transaction, turns `autocommit` mode back on.
The Python [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module by default issues a `BEGIN` statement implicitly before a Data Modification Language (DML) statement (i.e. `INSERT`/`UPDATE`/`DELETE`/`REPLACE`).
You can control which kind of `BEGIN` statements [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") implicitly executes via the *isolation\_level* parameter to the [`connect()`](#sqlite3.connect "sqlite3.connect")call, or via the `isolation_level` property of connections. If you specify no *isolation\_level*, a plain `BEGIN` is used, which is equivalent to specifying `DEFERRED`. Other possible values are `IMMEDIATE`and `EXCLUSIVE`.
You can disable the [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module's implicit transaction management by setting `isolation_level` to `None`. This will leave the underlying `sqlite3` library operating in `autocommit` mode. You can then completely control the transaction state by explicitly issuing `BEGIN`, `ROLLBACK`, `SAVEPOINT`, and `RELEASE` statements in your code.
在 3.6 版更改: [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") used to implicitly commit an open transaction before DDL statements. This is no longer the case.
## Using [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") efficiently
### Using shortcut methods
Using the nonstandard `execute()`, `executemany()` and `executescript()` methods of the [`Connection`](#sqlite3.Connection "sqlite3.Connection") object, your code can be written more concisely because you don't have to create the (often superfluous) [`Cursor`](#sqlite3.Cursor "sqlite3.Cursor") objects explicitly. Instead, the [`Cursor`](#sqlite3.Cursor "sqlite3.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`](#sqlite3.Connection "sqlite3.Connection") object.
```
import sqlite3
persons = [
("Hugo", "Boss"),
("Calvin", "Klein")
]
con = sqlite3.connect(":memory:")
# Create the table
con.execute("create table person(firstname, lastname)")
# Fill the table
con.executemany("insert into person(firstname, lastname) values (?, ?)", persons)
# Print the table contents
for row in con.execute("select firstname, lastname from person"):
print(row)
print("I just deleted", con.execute("delete from person").rowcount, "rows")
# close is not a shortcut method and it's not called automatically,
# so the connection object should be closed manually
con.close()
```
### Accessing columns by name instead of by index
One useful feature of the [`sqlite3`](#module-sqlite3 "sqlite3: A DB-API 2.0 implementation using SQLite 3.x.") module is the built-in [`sqlite3.Row`](#sqlite3.Row "sqlite3.Row") class designed to be used as a row factory.
Rows wrapped with this class can be accessed both by index (like tuples) and case-insensitively by name:
```
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()
```
### 使用连接作为上下文管理器
连接对象可以用来作为上下文管理器,它可以自动提交或者回滚事务。如果出现异常,事务会被回滚;否则,事务会被提交。
```
import sqlite3
con = sqlite3.connect(":memory:")
con.execute("create table person (id integer primary key, firstname varchar unique)")
# Successful, con.commit() is called automatically afterwards
with con:
con.execute("insert into person(firstname) values (?)", ("Joe",))
# 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 person(firstname) values (?)", ("Joe",))
except sqlite3.IntegrityError:
print("couldn't add Joe twice")
# Connection object used as context manager only commits or rollbacks transactions,
# so the connection object should be closed manually
con.close()
```
## 常见问题
### 多线程
Older SQLite versions had issues with sharing connections between threads. That's why the Python module disallows sharing connections and cursors between threads. If you still try to do so, you will get an exception at runtime.
The only exception is calling the [`interrupt()`](#sqlite3.Connection.interrupt "sqlite3.Connection.interrupt") method, which only makes sense to call from a different thread.
脚注
1([1](#id1),[2](#id2))sqlite3 模块默认没有构建可加载扩展支持,因为有一些平台带有不支持这个特性的 SQLite 库(特别是 Mac OS X)。要获得可加载扩展的支持,那么在编译配置的时候必须指定 --enable-loadable-sqlite-extensions 选项。
### 导航
- [索引](../genindex.xhtml "总目录")
- [模块](../py-modindex.xhtml "Python 模块索引") |
- [下一页](archiving.xhtml "数据压缩和存档") |
- [上一页](dbm.xhtml "dbm --- Interfaces to Unix "databases"") |
- ![](https://box.kancloud.cn/a721fc7ec672275e257bbbfde49a4d4e_16x16.png)
- [Python](https://www.python.org/) »
- zh\_CN 3.7.3 [文档](../index.xhtml) »
- [Python 标准库](index.xhtml) »
- [数据持久化](persistence.xhtml) »
- $('.inline-search').show(0); |
© [版权所有](../copyright.xhtml) 2001-2019, Python Software Foundation.
Python 软件基金会是一个非盈利组织。 [请捐助。](https://www.python.org/psf/donations/)
最后更新于 5月 21, 2019. [发现了问题](../bugs.xhtml)?
使用[Sphinx](http://sphinx.pocoo.org/)1.8.4 创建。
- Python文档内容
- Python 有什么新变化?
- Python 3.7 有什么新变化
- 摘要 - 发布重点
- 新的特性
- 其他语言特性修改
- 新增模块
- 改进的模块
- C API 的改变
- 构建的改变
- 性能优化
- 其他 CPython 实现的改变
- 已弃用的 Python 行为
- 已弃用的 Python 模块、函数和方法
- 已弃用的 C API 函数和类型
- 平台支持的移除
- API 与特性的移除
- 移除的模块
- Windows 专属的改变
- 移植到 Python 3.7
- Python 3.7.1 中的重要变化
- Python 3.7.2 中的重要变化
- Python 3.6 有什么新变化A
- 摘要 - 发布重点
- 新的特性
- 其他语言特性修改
- 新增模块
- 改进的模块
- 性能优化
- Build and C API Changes
- 其他改进
- 弃用
- 移除
- 移植到Python 3.6
- Python 3.6.2 中的重要变化
- Python 3.6.4 中的重要变化
- Python 3.6.5 中的重要变化
- Python 3.6.7 中的重要变化
- Python 3.5 有什么新变化
- 摘要 - 发布重点
- 新的特性
- 其他语言特性修改
- 新增模块
- 改进的模块
- Other module-level changes
- 性能优化
- Build and C API Changes
- 弃用
- 移除
- Porting to Python 3.5
- Notable changes in Python 3.5.4
- What's New In Python 3.4
- 摘要 - 发布重点
- 新的特性
- 新增模块
- 改进的模块
- CPython Implementation Changes
- 弃用
- 移除
- Porting to Python 3.4
- Changed in 3.4.3
- What's New In Python 3.3
- 摘要 - 发布重点
- PEP 405: Virtual Environments
- PEP 420: Implicit Namespace Packages
- PEP 3118: New memoryview implementation and buffer protocol documentation
- PEP 393: Flexible String Representation
- PEP 397: Python Launcher for Windows
- PEP 3151: Reworking the OS and IO exception hierarchy
- PEP 380: Syntax for Delegating to a Subgenerator
- PEP 409: Suppressing exception context
- PEP 414: Explicit Unicode literals
- PEP 3155: Qualified name for classes and functions
- PEP 412: Key-Sharing Dictionary
- PEP 362: Function Signature Object
- PEP 421: Adding sys.implementation
- Using importlib as the Implementation of Import
- 其他语言特性修改
- A Finer-Grained Import Lock
- Builtin functions and types
- 新增模块
- 改进的模块
- 性能优化
- Build and C API Changes
- 弃用
- Porting to Python 3.3
- What's New In Python 3.2
- PEP 384: Defining a Stable ABI
- PEP 389: Argparse Command Line Parsing Module
- PEP 391: Dictionary Based Configuration for Logging
- PEP 3148: The concurrent.futures module
- PEP 3147: PYC Repository Directories
- PEP 3149: ABI Version Tagged .so Files
- PEP 3333: Python Web Server Gateway Interface v1.0.1
- 其他语言特性修改
- New, Improved, and Deprecated Modules
- 多线程
- 性能优化
- Unicode
- Codecs
- 文档
- IDLE
- Code Repository
- Build and C API Changes
- Porting to Python 3.2
- What's New In Python 3.1
- PEP 372: Ordered Dictionaries
- PEP 378: Format Specifier for Thousands Separator
- 其他语言特性修改
- New, Improved, and Deprecated Modules
- 性能优化
- IDLE
- Build and C API Changes
- Porting to Python 3.1
- What's New In Python 3.0
- Common Stumbling Blocks
- Overview Of Syntax Changes
- Changes Already Present In Python 2.6
- Library Changes
- PEP 3101: A New Approach To String Formatting
- Changes To Exceptions
- Miscellaneous Other Changes
- Build and C API Changes
- 性能
- Porting To Python 3.0
- What's New in Python 2.7
- The Future for Python 2.x
- Changes to the Handling of Deprecation Warnings
- Python 3.1 Features
- PEP 372: Adding an Ordered Dictionary to collections
- PEP 378: Format Specifier for Thousands Separator
- PEP 389: The argparse Module for Parsing Command Lines
- PEP 391: Dictionary-Based Configuration For Logging
- PEP 3106: Dictionary Views
- PEP 3137: The memoryview Object
- 其他语言特性修改
- New and Improved Modules
- Build and C API Changes
- Other Changes and Fixes
- Porting to Python 2.7
- New Features Added to Python 2.7 Maintenance Releases
- Acknowledgements
- Python 2.6 有什么新变化
- Python 3.0
- Changes to the Development Process
- PEP 343: The 'with' statement
- PEP 366: Explicit Relative Imports From a Main Module
- PEP 370: Per-user site-packages Directory
- PEP 371: The multiprocessing Package
- PEP 3101: Advanced String Formatting
- PEP 3105: print As a Function
- PEP 3110: Exception-Handling Changes
- PEP 3112: Byte Literals
- PEP 3116: New I/O Library
- PEP 3118: Revised Buffer Protocol
- PEP 3119: Abstract Base Classes
- PEP 3127: Integer Literal Support and Syntax
- PEP 3129: Class Decorators
- PEP 3141: A Type Hierarchy for Numbers
- 其他语言特性修改
- New and Improved Modules
- Deprecations and Removals
- Build and C API Changes
- Porting to Python 2.6
- Acknowledgements
- What's New in Python 2.5
- PEP 308: Conditional Expressions
- PEP 309: Partial Function Application
- PEP 314: Metadata for Python Software Packages v1.1
- PEP 328: Absolute and Relative Imports
- PEP 338: Executing Modules as Scripts
- PEP 341: Unified try/except/finally
- PEP 342: New Generator Features
- PEP 343: The 'with' statement
- PEP 352: Exceptions as New-Style Classes
- PEP 353: Using ssize_t as the index type
- PEP 357: The 'index' method
- 其他语言特性修改
- New, Improved, and Removed Modules
- Build and C API Changes
- Porting to Python 2.5
- Acknowledgements
- What's New in Python 2.4
- PEP 218: Built-In Set Objects
- PEP 237: Unifying Long Integers and Integers
- PEP 289: Generator Expressions
- PEP 292: Simpler String Substitutions
- PEP 318: Decorators for Functions and Methods
- PEP 322: Reverse Iteration
- PEP 324: New subprocess Module
- PEP 327: Decimal Data Type
- PEP 328: Multi-line Imports
- PEP 331: Locale-Independent Float/String Conversions
- 其他语言特性修改
- New, Improved, and Deprecated Modules
- Build and C API Changes
- Porting to Python 2.4
- Acknowledgements
- What's New in Python 2.3
- PEP 218: A Standard Set Datatype
- PEP 255: Simple Generators
- PEP 263: Source Code Encodings
- PEP 273: Importing Modules from ZIP Archives
- PEP 277: Unicode file name support for Windows NT
- PEP 278: Universal Newline Support
- PEP 279: enumerate()
- PEP 282: The logging Package
- PEP 285: A Boolean Type
- PEP 293: Codec Error Handling Callbacks
- PEP 301: Package Index and Metadata for Distutils
- PEP 302: New Import Hooks
- PEP 305: Comma-separated Files
- PEP 307: Pickle Enhancements
- Extended Slices
- 其他语言特性修改
- New, Improved, and Deprecated Modules
- Pymalloc: A Specialized Object Allocator
- Build and C API Changes
- Other Changes and Fixes
- Porting to Python 2.3
- Acknowledgements
- What's New in Python 2.2
- 概述
- PEPs 252 and 253: Type and Class Changes
- PEP 234: Iterators
- PEP 255: Simple Generators
- PEP 237: Unifying Long Integers and Integers
- PEP 238: Changing the Division Operator
- Unicode Changes
- PEP 227: Nested Scopes
- New and Improved Modules
- Interpreter Changes and Fixes
- Other Changes and Fixes
- Acknowledgements
- What's New in Python 2.1
- 概述
- PEP 227: Nested Scopes
- PEP 236: future Directives
- PEP 207: Rich Comparisons
- PEP 230: Warning Framework
- PEP 229: New Build System
- PEP 205: Weak References
- PEP 232: Function Attributes
- PEP 235: Importing Modules on Case-Insensitive Platforms
- PEP 217: Interactive Display Hook
- PEP 208: New Coercion Model
- PEP 241: Metadata in Python Packages
- New and Improved Modules
- Other Changes and Fixes
- Acknowledgements
- What's New in Python 2.0
- 概述
- What About Python 1.6?
- New Development Process
- Unicode
- 列表推导式
- Augmented Assignment
- 字符串的方法
- Garbage Collection of Cycles
- Other Core Changes
- Porting to 2.0
- Extending/Embedding Changes
- Distutils: Making Modules Easy to Install
- XML Modules
- Module changes
- New modules
- IDLE Improvements
- Deleted and Deprecated Modules
- Acknowledgements
- 更新日志
- Python 下一版
- Python 3.7.3 最终版
- Python 3.7.3 发布候选版 1
- Python 3.7.2 最终版
- Python 3.7.2 发布候选版 1
- Python 3.7.1 最终版
- Python 3.7.1 RC 2版本
- Python 3.7.1 发布候选版 1
- Python 3.7.0 正式版
- Python 3.7.0 release candidate 1
- Python 3.7.0 beta 5
- Python 3.7.0 beta 4
- Python 3.7.0 beta 3
- Python 3.7.0 beta 2
- Python 3.7.0 beta 1
- Python 3.7.0 alpha 4
- Python 3.7.0 alpha 3
- Python 3.7.0 alpha 2
- Python 3.7.0 alpha 1
- Python 3.6.6 final
- Python 3.6.6 RC 1
- Python 3.6.5 final
- Python 3.6.5 release candidate 1
- Python 3.6.4 final
- Python 3.6.4 release candidate 1
- Python 3.6.3 final
- Python 3.6.3 release candidate 1
- Python 3.6.2 final
- Python 3.6.2 release candidate 2
- Python 3.6.2 release candidate 1
- Python 3.6.1 final
- Python 3.6.1 release candidate 1
- Python 3.6.0 final
- Python 3.6.0 release candidate 2
- Python 3.6.0 release candidate 1
- Python 3.6.0 beta 4
- Python 3.6.0 beta 3
- Python 3.6.0 beta 2
- Python 3.6.0 beta 1
- Python 3.6.0 alpha 4
- Python 3.6.0 alpha 3
- Python 3.6.0 alpha 2
- Python 3.6.0 alpha 1
- Python 3.5.5 final
- Python 3.5.5 release candidate 1
- Python 3.5.4 final
- Python 3.5.4 release candidate 1
- Python 3.5.3 final
- Python 3.5.3 release candidate 1
- Python 3.5.2 final
- Python 3.5.2 release candidate 1
- Python 3.5.1 final
- Python 3.5.1 release candidate 1
- Python 3.5.0 final
- Python 3.5.0 release candidate 4
- Python 3.5.0 release candidate 3
- Python 3.5.0 release candidate 2
- Python 3.5.0 release candidate 1
- Python 3.5.0 beta 4
- Python 3.5.0 beta 3
- Python 3.5.0 beta 2
- Python 3.5.0 beta 1
- Python 3.5.0 alpha 4
- Python 3.5.0 alpha 3
- Python 3.5.0 alpha 2
- Python 3.5.0 alpha 1
- Python 教程
- 课前甜点
- 使用 Python 解释器
- 调用解释器
- 解释器的运行环境
- Python 的非正式介绍
- Python 作为计算器使用
- 走向编程的第一步
- 其他流程控制工具
- if 语句
- for 语句
- range() 函数
- break 和 continue 语句,以及循环中的 else 子句
- pass 语句
- 定义函数
- 函数定义的更多形式
- 小插曲:编码风格
- 数据结构
- 列表的更多特性
- del 语句
- 元组和序列
- 集合
- 字典
- 循环的技巧
- 深入条件控制
- 序列和其它类型的比较
- 模块
- 有关模块的更多信息
- 标准模块
- dir() 函数
- 包
- 输入输出
- 更漂亮的输出格式
- 读写文件
- 错误和异常
- 语法错误
- 异常
- 处理异常
- 抛出异常
- 用户自定义异常
- 定义清理操作
- 预定义的清理操作
- 类
- 名称和对象
- Python 作用域和命名空间
- 初探类
- 补充说明
- 继承
- 私有变量
- 杂项说明
- 迭代器
- 生成器
- 生成器表达式
- 标准库简介
- 操作系统接口
- 文件通配符
- 命令行参数
- 错误输出重定向和程序终止
- 字符串模式匹配
- 数学
- 互联网访问
- 日期和时间
- 数据压缩
- 性能测量
- 质量控制
- 自带电池
- 标准库简介 —— 第二部分
- 格式化输出
- 模板
- 使用二进制数据记录格式
- 多线程
- 日志
- 弱引用
- 用于操作列表的工具
- 十进制浮点运算
- 虚拟环境和包
- 概述
- 创建虚拟环境
- 使用pip管理包
- 接下来?
- 交互式编辑和编辑历史
- Tab 补全和编辑历史
- 默认交互式解释器的替代品
- 浮点算术:争议和限制
- 表示性错误
- 附录
- 交互模式
- 安装和使用 Python
- 命令行与环境
- 命令行
- 环境变量
- 在Unix平台中使用Python
- 获取最新版本的Python
- 构建Python
- 与Python相关的路径和文件
- 杂项
- 编辑器和集成开发环境
- 在Windows上使用 Python
- 完整安装程序
- Microsoft Store包
- nuget.org 安装包
- 可嵌入的包
- 替代捆绑包
- 配置Python
- 适用于Windows的Python启动器
- 查找模块
- 附加模块
- 在Windows上编译Python
- 其他平台
- 在苹果系统上使用 Python
- 获取和安装 MacPython
- IDE
- 安装额外的 Python 包
- Mac 上的图形界面编程
- 在 Mac 上分发 Python 应用程序
- 其他资源
- Python 语言参考
- 概述
- 其他实现
- 标注
- 词法分析
- 行结构
- 其他形符
- 标识符和关键字
- 字面值
- 运算符
- 分隔符
- 数据模型
- 对象、值与类型
- 标准类型层级结构
- 特殊方法名称
- 协程
- 执行模型
- 程序的结构
- 命名与绑定
- 异常
- 导入系统
- importlib
- 包
- 搜索
- 加载
- 基于路径的查找器
- 替换标准导入系统
- Package Relative Imports
- 有关 main 的特殊事项
- 开放问题项
- 参考文献
- 表达式
- 算术转换
- 原子
- 原型
- await 表达式
- 幂运算符
- 一元算术和位运算
- 二元算术运算符
- 移位运算
- 二元位运算
- 比较运算
- 布尔运算
- 条件表达式
- lambda 表达式
- 表达式列表
- 求值顺序
- 运算符优先级
- 简单语句
- 表达式语句
- 赋值语句
- assert 语句
- pass 语句
- del 语句
- return 语句
- yield 语句
- raise 语句
- break 语句
- continue 语句
- import 语句
- global 语句
- nonlocal 语句
- 复合语句
- if 语句
- while 语句
- for 语句
- try 语句
- with 语句
- 函数定义
- 类定义
- 协程
- 最高层级组件
- 完整的 Python 程序
- 文件输入
- 交互式输入
- 表达式输入
- 完整的语法规范
- Python 标准库
- 概述
- 可用性注释
- 内置函数
- 内置常量
- 由 site 模块添加的常量
- 内置类型
- 逻辑值检测
- 布尔运算 — and, or, not
- 比较
- 数字类型 — int, float, complex
- 迭代器类型
- 序列类型 — list, tuple, range
- 文本序列类型 — str
- 二进制序列类型 — bytes, bytearray, memoryview
- 集合类型 — set, frozenset
- 映射类型 — dict
- 上下文管理器类型
- 其他内置类型
- 特殊属性
- 内置异常
- 基类
- 具体异常
- 警告
- 异常层次结构
- 文本处理服务
- string — 常见的字符串操作
- re — 正则表达式操作
- 模块 difflib 是一个计算差异的助手
- textwrap — Text wrapping and filling
- unicodedata — Unicode 数据库
- stringprep — Internet String Preparation
- readline — GNU readline interface
- rlcompleter — GNU readline的完成函数
- 二进制数据服务
- struct — Interpret bytes as packed binary data
- codecs — Codec registry and base classes
- 数据类型
- datetime — 基础日期/时间数据类型
- calendar — General calendar-related functions
- collections — 容器数据类型
- collections.abc — 容器的抽象基类
- heapq — 堆队列算法
- bisect — Array bisection algorithm
- array — Efficient arrays of numeric values
- weakref — 弱引用
- types — Dynamic type creation and names for built-in types
- copy — 浅层 (shallow) 和深层 (deep) 复制操作
- pprint — 数据美化输出
- reprlib — Alternate repr() implementation
- enum — Support for enumerations
- 数字和数学模块
- numbers — 数字的抽象基类
- math — 数学函数
- cmath — Mathematical functions for complex numbers
- decimal — 十进制定点和浮点运算
- fractions — 分数
- random — 生成伪随机数
- statistics — Mathematical statistics functions
- 函数式编程模块
- itertools — 为高效循环而创建迭代器的函数
- functools — 高阶函数和可调用对象上的操作
- operator — 标准运算符替代函数
- 文件和目录访问
- pathlib — 面向对象的文件系统路径
- os.path — 常见路径操作
- fileinput — Iterate over lines from multiple input streams
- stat — Interpreting stat() results
- filecmp — File and Directory Comparisons
- tempfile — Generate temporary files and directories
- glob — Unix style pathname pattern expansion
- fnmatch — Unix filename pattern matching
- linecache — Random access to text lines
- shutil — High-level file operations
- macpath — Mac OS 9 路径操作函数
- 数据持久化
- pickle —— Python 对象序列化
- copyreg — Register pickle support functions
- shelve — Python object persistence
- marshal — Internal Python object serialization
- dbm — Interfaces to Unix “databases”
- sqlite3 — SQLite 数据库 DB-API 2.0 接口模块
- 数据压缩和存档
- zlib — 与 gzip 兼容的压缩
- gzip — 对 gzip 格式的支持
- bz2 — 对 bzip2 压缩算法的支持
- lzma — 用 LZMA 算法压缩
- zipfile — 在 ZIP 归档中工作
- tarfile — Read and write tar archive files
- 文件格式
- csv — CSV 文件读写
- configparser — Configuration file parser
- netrc — netrc file processing
- xdrlib — Encode and decode XDR data
- plistlib — Generate and parse Mac OS X .plist files
- 加密服务
- hashlib — 安全哈希与消息摘要
- hmac — 基于密钥的消息验证
- secrets — Generate secure random numbers for managing secrets
- 通用操作系统服务
- os — 操作系统接口模块
- io — 处理流的核心工具
- time — 时间的访问和转换
- argparse — 命令行选项、参数和子命令解析器
- getopt — C-style parser for command line options
- 模块 logging — Python 的日志记录工具
- logging.config — 日志记录配置
- logging.handlers — Logging handlers
- getpass — 便携式密码输入工具
- curses — 终端字符单元显示的处理
- curses.textpad — Text input widget for curses programs
- curses.ascii — Utilities for ASCII characters
- curses.panel — A panel stack extension for curses
- platform — Access to underlying platform's identifying data
- errno — Standard errno system symbols
- ctypes — Python 的外部函数库
- 并发执行
- threading — 基于线程的并行
- multiprocessing — 基于进程的并行
- concurrent 包
- concurrent.futures — 启动并行任务
- subprocess — 子进程管理
- sched — 事件调度器
- queue — 一个同步的队列类
- _thread — 底层多线程 API
- _dummy_thread — _thread 的替代模块
- dummy_threading — 可直接替代 threading 模块。
- contextvars — Context Variables
- Context Variables
- Manual Context Management
- asyncio support
- 网络和进程间通信
- asyncio — 异步 I/O
- socket — 底层网络接口
- ssl — TLS/SSL wrapper for socket objects
- select — Waiting for I/O completion
- selectors — 高级 I/O 复用库
- asyncore — 异步socket处理器
- asynchat — 异步 socket 指令/响应 处理器
- signal — Set handlers for asynchronous events
- mmap — Memory-mapped file support
- 互联网数据处理
- email — 电子邮件与 MIME 处理包
- json — JSON 编码和解码器
- mailcap — Mailcap file handling
- mailbox — Manipulate mailboxes in various formats
- mimetypes — Map filenames to MIME types
- base64 — Base16, Base32, Base64, Base85 数据编码
- binhex — 对binhex4文件进行编码和解码
- binascii — 二进制和 ASCII 码互转
- quopri — Encode and decode MIME quoted-printable data
- uu — Encode and decode uuencode files
- 结构化标记处理工具
- html — 超文本标记语言支持
- html.parser — 简单的 HTML 和 XHTML 解析器
- html.entities — HTML 一般实体的定义
- XML处理模块
- xml.etree.ElementTree — The ElementTree XML API
- xml.dom — The Document Object Model API
- xml.dom.minidom — Minimal DOM implementation
- xml.dom.pulldom — Support for building partial DOM trees
- xml.sax — Support for SAX2 parsers
- xml.sax.handler — Base classes for SAX handlers
- xml.sax.saxutils — SAX Utilities
- xml.sax.xmlreader — Interface for XML parsers
- xml.parsers.expat — Fast XML parsing using Expat
- 互联网协议和支持
- webbrowser — 方便的Web浏览器控制器
- cgi — Common Gateway Interface support
- cgitb — Traceback manager for CGI scripts
- wsgiref — WSGI Utilities and Reference Implementation
- urllib — URL 处理模块
- urllib.request — 用于打开 URL 的可扩展库
- urllib.response — Response classes used by urllib
- urllib.parse — Parse URLs into components
- urllib.error — Exception classes raised by urllib.request
- urllib.robotparser — Parser for robots.txt
- http — HTTP 模块
- http.client — HTTP协议客户端
- ftplib — FTP protocol client
- poplib — POP3 protocol client
- imaplib — IMAP4 protocol client
- nntplib — NNTP protocol client
- smtplib —SMTP协议客户端
- smtpd — SMTP Server
- telnetlib — Telnet client
- uuid — UUID objects according to RFC 4122
- socketserver — A framework for network servers
- http.server — HTTP 服务器
- http.cookies — HTTP state management
- http.cookiejar — Cookie handling for HTTP clients
- xmlrpc — XMLRPC 服务端与客户端模块
- xmlrpc.client — XML-RPC client access
- xmlrpc.server — Basic XML-RPC servers
- ipaddress — IPv4/IPv6 manipulation library
- 多媒体服务
- audioop — Manipulate raw audio data
- aifc — Read and write AIFF and AIFC files
- sunau — 读写 Sun AU 文件
- wave — 读写WAV格式文件
- chunk — Read IFF chunked data
- colorsys — Conversions between color systems
- imghdr — 推测图像类型
- sndhdr — 推测声音文件的类型
- ossaudiodev — Access to OSS-compatible audio devices
- 国际化
- gettext — 多语种国际化服务
- locale — 国际化服务
- 程序框架
- turtle — 海龟绘图
- cmd — 支持面向行的命令解释器
- shlex — Simple lexical analysis
- Tk图形用户界面(GUI)
- tkinter — Tcl/Tk的Python接口
- tkinter.ttk — Tk themed widgets
- tkinter.tix — Extension widgets for Tk
- tkinter.scrolledtext — 滚动文字控件
- IDLE
- 其他图形用户界面(GUI)包
- 开发工具
- typing — 类型标注支持
- pydoc — Documentation generator and online help system
- doctest — Test interactive Python examples
- unittest — 单元测试框架
- unittest.mock — mock object library
- unittest.mock 上手指南
- 2to3 - 自动将 Python 2 代码转为 Python 3 代码
- test — Regression tests package for Python
- test.support — Utilities for the Python test suite
- test.support.script_helper — Utilities for the Python execution tests
- 调试和分析
- bdb — Debugger framework
- faulthandler — Dump the Python traceback
- pdb — The Python Debugger
- The Python Profilers
- timeit — 测量小代码片段的执行时间
- trace — Trace or track Python statement execution
- tracemalloc — Trace memory allocations
- 软件打包和分发
- distutils — 构建和安装 Python 模块
- ensurepip — Bootstrapping the pip installer
- venv — 创建虚拟环境
- zipapp — Manage executable Python zip archives
- Python运行时服务
- sys — 系统相关的参数和函数
- sysconfig — Provide access to Python's configuration information
- builtins — 内建对象
- main — 顶层脚本环境
- warnings — Warning control
- dataclasses — 数据类
- contextlib — Utilities for with-statement contexts
- abc — 抽象基类
- atexit — 退出处理器
- traceback — Print or retrieve a stack traceback
- future — Future 语句定义
- gc — 垃圾回收器接口
- inspect — 检查对象
- site — Site-specific configuration hook
- 自定义 Python 解释器
- code — Interpreter base classes
- codeop — Compile Python code
- 导入模块
- zipimport — Import modules from Zip archives
- pkgutil — Package extension utility
- modulefinder — 查找脚本使用的模块
- runpy — Locating and executing Python modules
- importlib — The implementation of import
- Python 语言服务
- parser — Access Python parse trees
- ast — 抽象语法树
- symtable — Access to the compiler's symbol tables
- symbol — 与 Python 解析树一起使用的常量
- token — 与Python解析树一起使用的常量
- keyword — 检验Python关键字
- tokenize — Tokenizer for Python source
- tabnanny — 模糊缩进检测
- pyclbr — Python class browser support
- py_compile — Compile Python source files
- compileall — Byte-compile Python libraries
- dis — Python 字节码反汇编器
- pickletools — Tools for pickle developers
- 杂项服务
- formatter — Generic output formatting
- Windows系统相关模块
- msilib — Read and write Microsoft Installer files
- msvcrt — Useful routines from the MS VC++ runtime
- winreg — Windows 注册表访问
- winsound — Sound-playing interface for Windows
- Unix 专有服务
- posix — The most common POSIX system calls
- pwd — 用户密码数据库
- spwd — The shadow password database
- grp — The group database
- crypt — Function to check Unix passwords
- termios — POSIX style tty control
- tty — 终端控制功能
- pty — Pseudo-terminal utilities
- fcntl — The fcntl and ioctl system calls
- pipes — Interface to shell pipelines
- resource — Resource usage information
- nis — Interface to Sun's NIS (Yellow Pages)
- Unix syslog 库例程
- 被取代的模块
- optparse — Parser for command line options
- imp — Access the import internals
- 未创建文档的模块
- 平台特定模块
- 扩展和嵌入 Python 解释器
- 推荐的第三方工具
- 不使用第三方工具创建扩展
- 使用 C 或 C++ 扩展 Python
- 自定义扩展类型:教程
- 定义扩展类型:已分类主题
- 构建C/C++扩展
- 在Windows平台编译C和C++扩展
- 在更大的应用程序中嵌入 CPython 运行时
- Embedding Python in Another Application
- Python/C API 参考手册
- 概述
- 代码标准
- 包含文件
- 有用的宏
- 对象、类型和引用计数
- 异常
- 嵌入Python
- 调试构建
- 稳定的应用程序二进制接口
- The Very High Level Layer
- Reference Counting
- 异常处理
- Printing and clearing
- 抛出异常
- Issuing warnings
- Querying the error indicator
- Signal Handling
- Exception Classes
- Exception Objects
- Unicode Exception Objects
- Recursion Control
- 标准异常
- 标准警告类别
- 工具
- 操作系统实用程序
- 系统功能
- 过程控制
- 导入模块
- Data marshalling support
- 语句解释及变量编译
- 字符串转换与格式化
- 反射
- 编解码器注册与支持功能
- 抽象对象层
- Object Protocol
- 数字协议
- Sequence Protocol
- Mapping Protocol
- 迭代器协议
- 缓冲协议
- Old Buffer Protocol
- 具体的对象层
- 基本对象
- 数值对象
- 序列对象
- 容器对象
- 函数对象
- 其他对象
- Initialization, Finalization, and Threads
- 在Python初始化之前
- 全局配置变量
- Initializing and finalizing the interpreter
- Process-wide parameters
- Thread State and the Global Interpreter Lock
- Sub-interpreter support
- Asynchronous Notifications
- Profiling and Tracing
- Advanced Debugger Support
- Thread Local Storage Support
- 内存管理
- 概述
- 原始内存接口
- Memory Interface
- 对象分配器
- 默认内存分配器
- Customize Memory Allocators
- The pymalloc allocator
- tracemalloc C API
- 示例
- 对象实现支持
- 在堆中分配对象
- Common Object Structures
- Type 对象
- Number Object Structures
- Mapping Object Structures
- Sequence Object Structures
- Buffer Object Structures
- Async Object Structures
- 使对象类型支持循环垃圾回收
- API 和 ABI 版本管理
- 分发 Python 模块
- 关键术语
- 开源许可与协作
- 安装工具
- 阅读指南
- 我该如何...?
- ...为我的项目选择一个名字?
- ...创建和分发二进制扩展?
- 安装 Python 模块
- 关键术语
- 基本使用
- 我应如何 ...?
- ... 在 Python 3.4 之前的 Python 版本中安装 pip ?
- ... 只为当前用户安装软件包?
- ... 安装科学计算类 Python 软件包?
- ... 使用并行安装的多个 Python 版本?
- 常见的安装问题
- 在 Linux 的系统 Python 版本上安装
- 未安装 pip
- 安装二进制编译扩展
- Python 常用指引
- 将 Python 2 代码迁移到 Python 3
- 简要说明
- 详情
- 将扩展模块移植到 Python 3
- 条件编译
- 对象API的更改
- 模块初始化和状态
- CObject 替换为 Capsule
- 其他选项
- Curses Programming with Python
- What is curses?
- Starting and ending a curses application
- Windows and Pads
- Displaying Text
- User Input
- For More Information
- 实现描述器
- 摘要
- 定义和简介
- 描述器协议
- 发起调用描述符
- 描述符示例
- Properties
- 函数和方法
- Static Methods and Class Methods
- 函数式编程指引
- 概述
- 迭代器
- 生成器表达式和列表推导式
- 生成器
- 内置函数
- itertools 模块
- The functools module
- Small functions and the lambda expression
- Revision History and Acknowledgements
- 引用文献
- 日志 HOWTO
- 日志基础教程
- 进阶日志教程
- 日志级别
- 有用的处理程序
- 记录日志中引发的异常
- 使用任意对象作为消息
- 优化
- 日志操作手册
- 在多个模块中使用日志
- 在多线程中使用日志
- 使用多个日志处理器和多种格式化
- 在多个地方记录日志
- 日志服务器配置示例
- 处理日志处理器的阻塞
- Sending and receiving logging events across a network
- Adding contextual information to your logging output
- Logging to a single file from multiple processes
- Using file rotation
- Use of alternative formatting styles
- Customizing LogRecord
- Subclassing QueueHandler - a ZeroMQ example
- Subclassing QueueListener - a ZeroMQ example
- An example dictionary-based configuration
- Using a rotator and namer to customize log rotation processing
- A more elaborate multiprocessing example
- Inserting a BOM into messages sent to a SysLogHandler
- Implementing structured logging
- Customizing handlers with dictConfig()
- Using particular formatting styles throughout your application
- Configuring filters with dictConfig()
- Customized exception formatting
- Speaking logging messages
- Buffering logging messages and outputting them conditionally
- Formatting times using UTC (GMT) via configuration
- Using a context manager for selective logging
- 正则表达式HOWTO
- 概述
- 简单模式
- 使用正则表达式
- 更多模式能力
- 修改字符串
- 常见问题
- 反馈
- 套接字编程指南
- 套接字
- 创建套接字
- 使用一个套接字
- 断开连接
- 非阻塞的套接字
- 排序指南
- 基本排序
- 关键函数
- Operator 模块函数
- 升序和降序
- 排序稳定性和排序复杂度
- 使用装饰-排序-去装饰的旧方法
- 使用 cmp 参数的旧方法
- 其它
- Unicode 指南
- Unicode 概述
- Python's Unicode Support
- Reading and Writing Unicode Data
- Acknowledgements
- 如何使用urllib包获取网络资源
- 概述
- Fetching URLs
- 处理异常
- info and geturl
- Openers and Handlers
- Basic Authentication
- Proxies
- Sockets and Layers
- 脚注
- Argparse 教程
- 概念
- 基础
- 位置参数介绍
- Introducing Optional arguments
- Combining Positional and Optional arguments
- Getting a little more advanced
- Conclusion
- ipaddress模块介绍
- 创建 Address/Network/Interface 对象
- 审查 Address/Network/Interface 对象
- Network 作为 Address 列表
- 比较
- 将IP地址与其他模块一起使用
- 实例创建失败时获取更多详细信息
- Argument Clinic How-To
- The Goals Of Argument Clinic
- Basic Concepts And Usage
- Converting Your First Function
- Advanced Topics
- 使用 DTrace 和 SystemTap 检测CPython
- Enabling the static markers
- Static DTrace probes
- Static SystemTap markers
- Available static markers
- SystemTap Tapsets
- 示例
- Python 常见问题
- Python常见问题
- 一般信息
- 现实世界中的 Python
- 编程常见问题
- 一般问题
- 核心语言
- 数字和字符串
- 性能
- 序列(元组/列表)
- 对象
- 模块
- 设计和历史常见问题
- 为什么Python使用缩进来分组语句?
- 为什么简单的算术运算得到奇怪的结果?
- 为什么浮点计算不准确?
- 为什么Python字符串是不可变的?
- 为什么必须在方法定义和调用中显式使用“self”?
- 为什么不能在表达式中赋值?
- 为什么Python对某些功能(例如list.index())使用方法来实现,而其他功能(例如len(List))使用函数实现?
- 为什么 join()是一个字符串方法而不是列表或元组方法?
- 异常有多快?
- 为什么Python中没有switch或case语句?
- 难道不能在解释器中模拟线程,而非得依赖特定于操作系统的线程实现吗?
- 为什么lambda表达式不能包含语句?
- 可以将Python编译为机器代码,C或其他语言吗?
- Python如何管理内存?
- 为什么CPython不使用更传统的垃圾回收方案?
- CPython退出时为什么不释放所有内存?
- 为什么有单独的元组和列表数据类型?
- 列表是如何在CPython中实现的?
- 字典是如何在CPython中实现的?
- 为什么字典key必须是不可变的?
- 为什么 list.sort() 没有返回排序列表?
- 如何在Python中指定和实施接口规范?
- 为什么没有goto?
- 为什么原始字符串(r-strings)不能以反斜杠结尾?
- 为什么Python没有属性赋值的“with”语句?
- 为什么 if/while/def/class语句需要冒号?
- 为什么Python在列表和元组的末尾允许使用逗号?
- 代码库和插件 FAQ
- 通用的代码库问题
- 通用任务
- 线程相关
- 输入输出
- 网络 / Internet 编程
- 数据库
- 数学和数字
- 扩展/嵌入常见问题
- 可以使用C语言中创建自己的函数吗?
- 可以使用C++语言中创建自己的函数吗?
- C很难写,有没有其他选择?
- 如何从C执行任意Python语句?
- 如何从C中评估任意Python表达式?
- 如何从Python对象中提取C的值?
- 如何使用Py_BuildValue()创建任意长度的元组?
- 如何从C调用对象的方法?
- 如何捕获PyErr_Print()(或打印到stdout / stderr的任何内容)的输出?
- 如何从C访问用Python编写的模块?
- 如何从Python接口到C ++对象?
- 我使用Setup文件添加了一个模块,为什么make失败了?
- 如何调试扩展?
- 我想在Linux系统上编译一个Python模块,但是缺少一些文件。为什么?
- 如何区分“输入不完整”和“输入无效”?
- 如何找到未定义的g++符号__builtin_new或__pure_virtual?
- 能否创建一个对象类,其中部分方法在C中实现,而其他方法在Python中实现(例如通过继承)?
- Python在Windows上的常见问题
- 我怎样在Windows下运行一个Python程序?
- 我怎么让 Python 脚本可执行?
- 为什么有时候 Python 程序会启动缓慢?
- 我怎样使用Python脚本制作可执行文件?
- *.pyd 文件和DLL文件相同吗?
- 我怎样将Python嵌入一个Windows程序?
- 如何让编辑器不要在我的 Python 源代码中插入 tab ?
- 如何在不阻塞的情况下检查按键?
- 图形用户界面(GUI)常见问题
- 图形界面常见问题
- Python 是否有平台无关的图形界面工具包?
- 有哪些Python的GUI工具是某个平台专用的?
- 有关Tkinter的问题
- “为什么我的电脑上安装了 Python ?”
- 什么是Python?
- 为什么我的电脑上安装了 Python ?
- 我能删除 Python 吗?
- 术语对照表
- 文档说明
- Python 文档贡献者
- 解决 Bug
- 文档错误
- 使用 Python 的错误追踪系统
- 开始为 Python 贡献您的知识
- 版权
- 历史和许可证
- 软件历史
- 访问Python或以其他方式使用Python的条款和条件
- Python 3.7.3 的 PSF 许可协议
- Python 2.0 的 BeOpen.com 许可协议
- Python 1.6.1 的 CNRI 许可协议
- Python 0.9.0 至 1.2 的 CWI 许可协议
- 集成软件的许可和认可
- Mersenne Twister
- 套接字
- Asynchronous socket services
- Cookie management
- Execution tracing
- UUencode and UUdecode functions
- XML Remote Procedure Calls
- test_epoll
- Select kqueue
- SipHash24
- strtod and dtoa
- OpenSSL
- expat
- libffi
- zlib
- cfuhash
- libmpdec