diff options
author | Erlend E. Aasland <erlend.aasland@protonmail.com> | 2022-08-31 08:10:55 (GMT) |
---|---|---|
committer | GitHub <noreply@github.com> | 2022-08-31 08:10:55 (GMT) |
commit | 2ecc195498f3b1256fabc2b66e0d8f6d671fa1d7 (patch) | |
tree | 7f31823dd2fb5eeb5543b2f5c772091cdf92d8ff /Doc/library | |
parent | a0d0a77c1f78fee581294283a66bf198d69f2699 (diff) | |
download | cpython-2ecc195498f3b1256fabc2b66e0d8f6d671fa1d7.zip cpython-2ecc195498f3b1256fabc2b66e0d8f6d671fa1d7.tar.gz cpython-2ecc195498f3b1256fabc2b66e0d8f6d671fa1d7.tar.bz2 |
[3.10] gh-96414: Inline code examples in sqlite3 docs (GH-96442). (#96453)
* [3.10] gh-96414: Inline code examples in sqlite3 docs (GH-96442).
(cherry picked from commit f7e7bf161aaec5a5cffdcec7c97e1f09e445421b)
Co-authored-by: Erlend E. Aasland <erlend.aasland@protonmail.com>
Diffstat (limited to 'Doc/library')
-rw-r--r-- | Doc/library/sqlite3.rst | 319 |
1 files changed, 307 insertions, 12 deletions
diff --git a/Doc/library/sqlite3.rst b/Doc/library/sqlite3.rst index 27645b0..b24fa48 100644 --- a/Doc/library/sqlite3.rst +++ b/Doc/library/sqlite3.rst @@ -546,7 +546,25 @@ Connection objects Example: - .. literalinclude:: ../includes/sqlite3/row_factory.py + .. testcode:: + + 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.execute("SELECT 1 AS a") + print(cur.fetchone()["a"]) + + con.close() + + .. testoutput:: + :hide: + + 1 If returning a tuple doesn't suffice and you want name-based access to columns, you should consider setting :attr:`row_factory` to the @@ -567,7 +585,35 @@ Connection objects Example: - .. literalinclude:: ../includes/sqlite3/text_factory.py + .. testcode:: + + 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() .. attribute:: total_changes @@ -648,7 +694,16 @@ Connection objects Example: - .. literalinclude:: ../includes/sqlite3/md5func.py + .. doctest:: + + >>> import hashlib + >>> def md5sum(t): + ... return hashlib.md5(t).hexdigest() + >>> con = sqlite3.connect(":memory:") + >>> con.create_function("md5", 1, md5sum) + >>> for row in con.execute("SELECT md5(?)", (b"foo",)): + ... print(row) + ('acbd18db4cc2f85cedef654fccc4a4d8',) .. method:: create_aggregate(name, /, n_arg, aggregate_class) @@ -677,7 +732,32 @@ Connection objects Example: - .. literalinclude:: ../includes/sqlite3/mysumaggr.py + .. testcode:: + + 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.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() + + .. testoutput:: + :hide: + + 3 .. method:: create_collation(name, callable) @@ -692,7 +772,31 @@ Connection objects The following example shows a reverse sorting collation: - .. literalinclude:: ../includes/sqlite3/collation_reverse.py + .. testcode:: + + 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.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() + + .. testoutput:: + :hide: + + ('b',) + ('a',) Remove a collation function by setting *callable* to ``None``. @@ -788,7 +892,43 @@ Connection objects .. versionchanged:: 3.10 Added the ``sqlite3.enable_load_extension`` auditing event. - .. literalinclude:: ../includes/sqlite3/load_extension.py + .. testsetup:: sqlite3.loadext + + import sqlite3 + con = sqlite3.connect(":memory:") + + .. testcode:: sqlite3.loadext + :skipif: True # not testable at the moment + + 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() + + .. testoutput:: sqlite3.loadext + :hide: + + (2, 'broccoli pie', 'broccoli cheese onions flour') + (3, 'pumpkin pie', 'pumpkin sugar flour butter') .. method:: load_extension(path, /) @@ -1326,7 +1466,30 @@ placeholders (named style). For the qmark style, ``parameters`` must be a keys for all named parameters. Any extra items are ignored. Here's an example of both styles: -.. literalinclude:: ../includes/sqlite3/execute_1.py +.. testcode:: + + con = sqlite3.connect(":memory:") + cur = con.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()) + +.. testoutput:: + :hide: + + [('C', 1972)] .. _sqlite3-adapters: @@ -1360,7 +1523,26 @@ This can be implemented by adding a ``__conform__(self, protocol)`` method which returns the adapted value. The object passed to *protocol* will be of type :class:`PrepareProtocol`. -.. literalinclude:: ../includes/sqlite3/adapter_point_1.py +.. testcode:: + + class Point: + def __init__(self, x, y): + self.x, self.y = x, y + + def __conform__(self, protocol): + if protocol is sqlite3.PrepareProtocol: + return f"{self.x};{self.y}" + + con = sqlite3.connect(":memory:") + cur = con.cursor() + + cur.execute("SELECT ?", (Point(4.0, -3.2),)) + print(cur.fetchone()[0]) + +.. testoutput:: + :hide: + + 4.0;-3.2 How to register adapter callables @@ -1370,7 +1552,27 @@ The other possibility is to create a function that converts the Python object to an SQLite-compatible type. This function can then be registered using :func:`register_adapter`. -.. literalinclude:: ../includes/sqlite3/adapter_point_2.py +.. testcode:: + + class Point: + def __init__(self, x, y): + self.x, self.y = x, y + + def adapt_point(point): + return f"{point.x};{point.y}" + + sqlite3.register_adapter(Point, adapt_point) + + con = sqlite3.connect(":memory:") + cur = con.cursor() + + cur.execute("SELECT ?", (Point(1.0, 2.5),)) + print(cur.fetchone()[0]) + +.. testoutput:: + :hide: + + 1.0;2.5 .. _sqlite3-converters: @@ -1412,7 +1614,50 @@ of :func:`connect`. There are three options: The following example illustrates the implicit and explicit approaches: -.. literalinclude:: ../includes/sqlite3/converter_point.py +.. testcode:: + + 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]) + +.. testoutput:: + :hide: + + with declared types: Point(4.0, -3.2) + with column names: Point(4.0, -3.2) .. _sqlite3-adapter-converter-recipes: @@ -1474,7 +1719,33 @@ objects are created implicitly and these shortcut methods return the cursor objects. This way, you can execute a ``SELECT`` statement and iterate over it directly using only a single call on the :class:`Connection` object. -.. literalinclude:: ../includes/sqlite3/shortcut_methods.py +.. testcode:: + + # Create and fill the table. + con = sqlite3.connect(":memory:") + con.execute("CREATE TABLE lang(name, first_appeared)") + data = [ + ("C++", 1985), + ("Objective-C", 1984), + ] + con.executemany("INSERT INTO lang(name, first_appeared) VALUES(?, ?)", data) + + # 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; + # the connection object should be closed manually + con.close() + +.. testoutput:: + :hide: + + ('C++', 1985) + ('Objective-C', 1984) + I just deleted 2 rows .. _sqlite3-connection-context-manager: @@ -1499,7 +1770,31 @@ the context manager is a no-op. The context manager neither implicitly opens a new transaction nor closes the connection. -.. literalinclude:: ../includes/sqlite3/ctx_manager.py +.. testcode:: + + 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() + +.. testoutput:: + :hide: + + couldn't add Python twice .. _sqlite3-uri-tricks: |