Skip to content

Commit c87ea10

Browse files
erlend-aaslandCAM-Gerlachezio-melotti
authored
gh-95271: Rework sqlite3 tutorial (#95749)
Co-authored-by: C.A.M. Gerlach <[email protected]> Co-authored-by: Ezio Melotti <[email protected]>
1 parent cfaa79a commit c87ea10

File tree

1 file changed

+138
-50
lines changed

1 file changed

+138
-50
lines changed

Doc/library/sqlite3.rst

Lines changed: 138 additions & 50 deletions
Original file line numberDiff line numberDiff line change
@@ -47,85 +47,173 @@ This document includes four main sections:
4747
PEP written by Marc-André Lemburg.
4848

4949

50+
.. We use the following practises for SQL code:
51+
- UPPERCASE for keywords
52+
- snake_case for schema
53+
- single quotes for string literals
54+
- singular for table names
55+
- if needed, use double quotes for table and column names
56+
5057
.. _sqlite3-tutorial:
5158

5259
Tutorial
5360
--------
5461

55-
To use the module, start by creating a :class:`Connection` object that
56-
represents the database. Here the data will be stored in the
57-
:file:`example.db` file::
62+
In this tutorial, you will create a database of Monty Python movies
63+
using basic :mod:`!sqlite3` functionality.
64+
It assumes a fundamental understanding of database concepts,
65+
including `cursors`_ and `transactions`_.
66+
67+
First, we need to create a new database and open
68+
a database connection to allow :mod:`!sqlite3` to work with it.
69+
Call :func:`sqlite3.connect` to to create a connection to
70+
the database :file:`tutorial.db` in the current working directory,
71+
implicitly creating it if it does not exist::
5872

5973
import sqlite3
60-
con = sqlite3.connect('example.db')
74+
con = sqlite3.connect("tutorial.db")
6175

62-
The special path name ``:memory:`` can be provided to create a temporary
63-
database in RAM.
76+
The returned :class:`Connection` object ``con``
77+
represents the connection to the on-disk database.
6478

65-
Once a :class:`Connection` has been established, create a :class:`Cursor` object
66-
and call its :meth:`~Cursor.execute` method to perform SQL commands::
79+
In order to execute SQL statements and fetch results from SQL queries,
80+
we will need to use a database cursor.
81+
Call :meth:`con.cursor() <Connection.cursor>` to create the :class:`Cursor`::
6782

6883
cur = con.cursor()
6984

70-
# Create table
71-
cur.execute('''CREATE TABLE stocks
72-
(date text, trans text, symbol text, qty real, price real)''')
73-
74-
# Insert a row of data
75-
cur.execute("INSERT INTO stocks VALUES ('2006-01-05','BUY','RHAT',100,35.14)")
85+
Now that we've got a database connection and a cursor,
86+
we can create a database table ``movie`` with columns for title,
87+
release year, and review score.
88+
For simplicity, we can just use column names in the table declaration --
89+
thanks to the `flexible typing`_ feature of SQLite,
90+
specifying the data types is optional.
91+
Execute the ``CREATE TABLE`` statement
92+
by calling :meth:`cur.execute(...) <Cursor.execute>`::
93+
94+
cur.execute("CREATE TABLE movie(title, year, score)")
95+
96+
.. Ideally, we'd use sqlite_schema instead of sqlite_master below,
97+
but SQLite versions older than 3.33.0 do not recognise that variant.
98+
99+
We can verify that the new table has been created by querying
100+
the ``sqlite_master`` table built-in to SQLite,
101+
which should now contain an entry for the ``movie`` table definition
102+
(see `The Schema Table`_ for details).
103+
Execute that query by calling :meth:`cur.execute(...) <Cursor.execute>`,
104+
assign the result to ``res``,
105+
and call :meth:`res.fetchone() <Cursor.fetchone>` to fetch the resulting row::
106+
107+
>>> res = cur.execute("SELECT name FROM sqlite_master")
108+
>>> res.fetchone()
109+
('movie',)
110+
111+
We can see that the table has been created,
112+
as the query returns a :class:`tuple` containing the table's name.
113+
If we query ``sqlite_master`` for a non-existent table ``spam``,
114+
:meth:`!res.fetchone()` will return ``None``::
115+
116+
>>> res = cur.execute("SELECT name FROM sqlite_master WHERE name='spam'")
117+
>>> res.fetchone() is None
118+
True
119+
120+
Now, add two rows of data supplied as SQL literals
121+
by executing an ``INSERT`` statement,
122+
once again by calling :meth:`cur.execute(...) <Cursor.execute>`::
123+
124+
cur.execute("""
125+
INSERT INTO movie VALUES
126+
('Monty Python and the Holy Grail', 1975, 8.2),
127+
('And Now for Something Completely Different', 1971, 7.5)
128+
""")
129+
130+
The ``INSERT`` statement implicitly opens a transaction,
131+
which needs to be committed before changes are saved in the database
132+
(see :ref:`sqlite3-controlling-transactions` for details).
133+
Call :meth:`con.commit() <Connection.commit>` on the connection object
134+
to commit the transaction::
76135

77-
# Save (commit) the changes
78136
con.commit()
79137

80-
# We can also close the connection if we are done with it.
81-
# Just be sure any changes have been committed or they will be lost.
82-
con.close()
83-
84-
The saved data is persistent: it can be reloaded in a subsequent session even
85-
after restarting the Python interpreter::
86-
87-
import sqlite3
88-
con = sqlite3.connect('example.db')
89-
cur = con.cursor()
138+
We can verify that the data was inserted correctly
139+
by executing a ``SELECT`` query.
140+
Use the now-familiar :meth:`cur.execute(...) <Cursor.execute>` to
141+
assign the result to ``res``,
142+
and call :meth:`res.fetchall() <Cursor.fetchall>` to return all resulting rows::
90143

91-
At this point, our database only contains one row::
144+
>>> res = cur.execute("SELECT score FROM movie")
145+
>>> res.fetchall()
146+
[(8.2,), (7.5,)]
92147

93-
>>> res = cur.execute('SELECT count(rowid) FROM stocks')
94-
>>> print(res.fetchone())
95-
(1,)
148+
The result is a :class:`list` of two :class:`!tuple`\s, one per row,
149+
each containing that row's ``score`` value.
96150

97-
The result is a one-item :class:`tuple`:
98-
one row, with one column.
99-
Now, let us insert three more rows of data,
100-
using :meth:`~Cursor.executemany`::
151+
Now, insert three more rows by calling
152+
:meth:`cur.executemany(...) <Cursor.executemany>`::
101153

102-
>>> data = [
103-
... ('2006-03-28', 'BUY', 'IBM', 1000, 45.0),
104-
... ('2006-04-05', 'BUY', 'MSFT', 1000, 72.0),
105-
... ('2006-04-06', 'SELL', 'IBM', 500, 53.0),
106-
... ]
107-
>>> cur.executemany('INSERT INTO stocks VALUES(?, ?, ?, ?, ?)', data)
154+
data = [
155+
("Monty Python Live at the Hollywood Bowl", 1982, 7.9),
156+
("Monty Python's The Meaning of Life", 1983, 7.5),
157+
("Monty Python's Life of Brian", 1979, 8.0),
158+
]
159+
cur.executemany("INSERT INTO movie VALUES(?, ?, ?)", data)
160+
con.commit() # Remember to commit the transaction after executing INSERT.
108161

109-
Notice that we used ``?`` placeholders to bind *data* to the query.
162+
Notice that ``?`` placeholders are used to bind ``data`` to the query.
110163
Always use placeholders instead of :ref:`string formatting <tut-formatting>`
111164
to bind Python values to SQL statements,
112-
to avoid `SQL injection attacks`_.
113-
See the :ref:`placeholders how-to <sqlite3-placeholders>` for more details.
165+
to avoid `SQL injection attacks`_
166+
(see :ref:`sqlite3-placeholders` for more details).
114167

115-
Then, retrieve the data by iterating over the result of a ``SELECT`` statement::
168+
We can verify that the new rows were inserted
169+
by executing a ``SELECT`` query,
170+
this time iterating over the results of the query::
116171

117-
>>> for row in cur.execute('SELECT * FROM stocks ORDER BY price'):
172+
>>> for row in cur.execute("SELECT year, title FROM movie ORDER BY year"):
118173
... print(row)
174+
(1971, "And Now for Something Completely Different")
175+
(1975, "Monty Python and the Holy Grail")
176+
(1979, "Monty Python's Life of Brian")
177+
(1982, "Monty Python Live at the Hollywood Bowl")
178+
(1983, "Monty Python's The Meaning of Life")
179+
180+
Each row is a two-item :class:`tuple` of ``(year, title)``,
181+
matching the columns selected in the query.
182+
183+
Finally, verify that the database has been written to disk
184+
by calling :meth:`con.close() <Connection.close>`
185+
to close the existing connection, opening a new one,
186+
creating a new cursor, then querying the database::
187+
188+
>>> con.close()
189+
>>> new_con = sqlite3.connect("tutorial.db")
190+
>>> new_cur = new_con.cursor()
191+
>>> res = new_cur.execute("SELECT year, title FROM movie ORDER BY score DESC"):
192+
>>> title, year = res.fetchone()
193+
>>> print(f'The highest scoring Monty Python movie is {title!r}, released in {year}')
194+
'The highest scoring Monty Python movie is "Monty Python and the Holy Grail", released in 1975'
195+
196+
You've now created an SQLite database using the :mod:`!sqlite3` module,
197+
inserted data and retrieved values from it in multiple ways.
198+
199+
.. _SQL injection attacks: https://en.wikipedia.org/wiki/SQL_injection
200+
.. _The Schema Table: https://www.sqlite.org/schematab.html
201+
.. _cursors: https://en.wikipedia.org/wiki/Cursor_(databases)
202+
.. _flexible typing: https://www.sqlite.org/flextypegood.html
203+
.. _sqlite_master: https://www.sqlite.org/schematab.html
204+
.. _transactions: https://en.wikipedia.org/wiki/Database_transaction
119205

120-
('2006-01-05', 'BUY', 'RHAT', 100, 35.14)
121-
('2006-03-28', 'BUY', 'IBM', 1000, 45.0)
122-
('2006-04-06', 'SELL', 'IBM', 500, 53.0)
123-
('2006-04-05', 'BUY', 'MSFT', 1000, 72.0)
206+
.. seealso::
124207

125-
You've now created an SQLite database using the :mod:`!sqlite3` module.
208+
* :ref:`sqlite3-howtos` for further reading:
126209

127-
.. _SQL injection attacks: https://en.wikipedia.org/wiki/SQL_injection
210+
* :ref:`sqlite3-placeholders`
211+
* :ref:`sqlite3-adapters`
212+
* :ref:`sqlite3-converters`
213+
* :ref:`sqlite3-columns-by-name`
214+
* :ref:`sqlite3-connection-context-manager`
128215

216+
* :ref:`sqlite3-explanation` for in-depth background on transaction control.
129217

130218
.. _sqlite3-reference:
131219

0 commit comments

Comments
 (0)