Skip to content

[3.10] gh-95432: Add doctest for sqlite3 tutorial (GH-96193) #96201

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 1 commit into from
Aug 23, 2022
Merged
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
63 changes: 47 additions & 16 deletions Doc/library/sqlite3.rst
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,15 @@

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

.. Make sure we always doctest the tutorial with an empty database.

.. testsetup::

import sqlite3
src = sqlite3.connect(":memory:", isolation_level=None)
dst = sqlite3.connect("tutorial.db", isolation_level=None)
src.backup(dst)
del src, dst

.. _sqlite3-intro:

Expand Down Expand Up @@ -65,7 +74,9 @@ First, we need to create a new database and open
a database connection to allow :mod:`!sqlite3` to work with it.
Call :func:`sqlite3.connect` to to create a connection to
the database :file:`tutorial.db` in the current working directory,
implicitly creating it if it does not exist::
implicitly creating it if it does not exist:

.. testcode::

import sqlite3
con = sqlite3.connect("tutorial.db")
Expand All @@ -75,7 +86,9 @@ represents the connection to the on-disk database.

In order to execute SQL statements and fetch results from SQL queries,
we will need to use a database cursor.
Call :meth:`con.cursor() <Connection.cursor>` to create the :class:`Cursor`::
Call :meth:`con.cursor() <Connection.cursor>` to create the :class:`Cursor`:

.. testcode::

cur = con.cursor()

Expand All @@ -86,7 +99,9 @@ For simplicity, we can just use column names in the table declaration --
thanks to the `flexible typing`_ feature of SQLite,
specifying the data types is optional.
Execute the ``CREATE TABLE`` statement
by calling :meth:`cur.execute(...) <Cursor.execute>`::
by calling :meth:`cur.execute(...) <Cursor.execute>`:

.. testcode::

cur.execute("CREATE TABLE movie(title, year, score)")

Expand All @@ -99,7 +114,9 @@ which should now contain an entry for the ``movie`` table definition
(see `The Schema Table`_ for details).
Execute that query by calling :meth:`cur.execute(...) <Cursor.execute>`,
assign the result to ``res``,
and call :meth:`res.fetchone() <Cursor.fetchone>` to fetch the resulting row::
and call :meth:`res.fetchone() <Cursor.fetchone>` to fetch the resulting row:

.. doctest::

>>> res = cur.execute("SELECT name FROM sqlite_master")
>>> res.fetchone()
Expand All @@ -108,15 +125,19 @@ and call :meth:`res.fetchone() <Cursor.fetchone>` to fetch the resulting row::
We can see that the table has been created,
as the query returns a :class:`tuple` containing the table's name.
If we query ``sqlite_master`` for a non-existent table ``spam``,
:meth:`!res.fetchone()` will return ``None``::
:meth:`!res.fetchone()` will return ``None``:

.. doctest::

>>> res = cur.execute("SELECT name FROM sqlite_master WHERE name='spam'")
>>> res.fetchone() is None
True

Now, add two rows of data supplied as SQL literals
by executing an ``INSERT`` statement,
once again by calling :meth:`cur.execute(...) <Cursor.execute>`::
once again by calling :meth:`cur.execute(...) <Cursor.execute>`:

.. testcode::

cur.execute("""
INSERT INTO movie VALUES
Expand All @@ -128,15 +149,19 @@ The ``INSERT`` statement implicitly opens a transaction,
which needs to be committed before changes are saved in the database
(see :ref:`sqlite3-controlling-transactions` for details).
Call :meth:`con.commit() <Connection.commit>` on the connection object
to commit the transaction::
to commit the transaction:

.. testcode::

con.commit()

We can verify that the data was inserted correctly
by executing a ``SELECT`` query.
Use the now-familiar :meth:`cur.execute(...) <Cursor.execute>` to
assign the result to ``res``,
and call :meth:`res.fetchall() <Cursor.fetchall>` to return all resulting rows::
and call :meth:`res.fetchall() <Cursor.fetchall>` to return all resulting rows:

.. doctest::

>>> res = cur.execute("SELECT score FROM movie")
>>> res.fetchall()
Expand All @@ -146,7 +171,9 @@ The result is a :class:`list` of two :class:`!tuple`\s, one per row,
each containing that row's ``score`` value.

Now, insert three more rows by calling
:meth:`cur.executemany(...) <Cursor.executemany>`::
:meth:`cur.executemany(...) <Cursor.executemany>`:

.. testcode::

data = [
("Monty Python Live at the Hollywood Bowl", 1982, 7.9),
Expand All @@ -164,14 +191,16 @@ to avoid `SQL injection attacks`_

We can verify that the new rows were inserted
by executing a ``SELECT`` query,
this time iterating over the results of the query::
this time iterating over the results of the query:

.. doctest::

>>> for row in cur.execute("SELECT year, title FROM movie ORDER BY year"):
... print(row)
(1971, "And Now for Something Completely Different")
(1975, "Monty Python and the Holy Grail")
(1971, 'And Now for Something Completely Different')
(1975, 'Monty Python and the Holy Grail')
(1979, "Monty Python's Life of Brian")
(1982, "Monty Python Live at the Hollywood Bowl")
(1982, 'Monty Python Live at the Hollywood Bowl')
(1983, "Monty Python's The Meaning of Life")

Each row is a two-item :class:`tuple` of ``(year, title)``,
Expand All @@ -180,15 +209,17 @@ matching the columns selected in the query.
Finally, verify that the database has been written to disk
by calling :meth:`con.close() <Connection.close>`
to close the existing connection, opening a new one,
creating a new cursor, then querying the database::
creating a new cursor, then querying the database:

.. doctest::

>>> con.close()
>>> new_con = sqlite3.connect("tutorial.db")
>>> new_cur = new_con.cursor()
>>> res = new_cur.execute("SELECT year, title FROM movie ORDER BY score DESC"):
>>> res = new_cur.execute("SELECT title, year FROM movie ORDER BY score DESC")
>>> title, year = res.fetchone()
>>> print(f'The highest scoring Monty Python movie is {title!r}, released in {year}')
'The highest scoring Monty Python movie is "Monty Python and the Holy Grail", released in 1975'
The highest scoring Monty Python movie is 'Monty Python and the Holy Grail', released in 1975

You've now created an SQLite database using the :mod:`!sqlite3` module,
inserted data and retrieved values from it in multiple ways.
Expand Down