Skip to content
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

gh-96168: Add sqlite3 row factory how-to #99507

Merged
Merged
Changes from 2 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
116 changes: 83 additions & 33 deletions Doc/library/sqlite3.rst
Original file line number Diff line number Diff line change
Expand Up @@ -239,6 +239,7 @@ inserted data and retrieved values from it in multiple ways.
* :ref:`sqlite3-adapters`
* :ref:`sqlite3-converters`
* :ref:`sqlite3-connection-context-manager`
* :ref:`sqlite3-row-factory-how-to`

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

Expand Down Expand Up @@ -1320,27 +1321,11 @@ Connection objects
a :class:`Cursor` object and the raw row results as a :class:`tuple`,
and returns a custom object representing an SQLite row.
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

Example:

.. doctest::

>>> def dict_factory(cursor, row):
... col_names = [col[0] for col in cursor.description]
... return {key: value for key, value in zip(col_names, row)}
>>> con = sqlite3.connect(":memory:")
>>> con.row_factory = dict_factory
>>> for row in con.execute("SELECT 1 AS a, 2 AS b"):
... print(row)
{'a': 1, 'b': 2}

If returning a tuple doesn't suffice and you want name-based access to
columns, you should consider setting :attr:`row_factory` to the
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
highly optimized :class:`sqlite3.Row` type. :class:`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.
highly optimized :class:`sqlite3.Row`
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

.. XXX what's a db_row-based solution?
See :ref:`sqlite3-row-factory-how-to` for more details.
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

.. attribute:: text_factory

Expand Down Expand Up @@ -1611,6 +1596,8 @@ Row objects

Two row objects compare equal if have equal columns and equal members.
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

See :ref:`sqlite3-row-factory-how-to` for more details.
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

.. method:: keys

Return a :class:`list` of column names as :class:`strings <str>`.
Expand All @@ -1620,21 +1607,6 @@ Row objects
.. versionchanged:: 3.5
Added support of slicing.

Example:

.. doctest::

>>> con = sqlite3.connect(":memory:")
>>> con.row_factory = sqlite3.Row
>>> res = con.execute("SELECT 'Earth' AS name, 6378 AS radius")
>>> row = res.fetchone()
>>> row.keys()
['name', 'radius']
>>> row[0], row["name"] # Access by index and name.
('Earth', 'Earth')
>>> row["RADIUS"] # Column names are case-insensitive.
6378


.. _sqlite3-blob-objects:

Expand Down Expand Up @@ -2358,6 +2330,84 @@ can be found in the `SQLite URI documentation`_.
.. _SQLite URI documentation: https://www.sqlite.org/uri.html


.. _sqlite3-row-factory-how-to:
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

How to work with row factories
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

By default, :mod:`!sqlite3` represent fetched rows as :class:`tuples <tuple>`.
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
If a :class:`!tuple` does not suit your needs,
use the built-in :class:`Row` type or a custom :attr:`~Connection.row_factory`.
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
The former provides both indexed and case-insensitive named access to columns,
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
with low memory overhead and minimal performance impact.
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
Example use:
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

.. doctest::

>>> con = sqlite3.connect(":memory:")
>>> con.row_factory = sqlite3.Row
>>> res = con.execute("SELECT 'Earth' AS name, 6378 AS radius")
>>> row = res.fetchone()
>>> row.keys()
['name', 'radius']
>>> row[0], row["name"] # Access by index and name.
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
('Earth', 'Earth')
>>> row["RADIUS"] # Column names are case-insensitive.
6378

If you need more flexibility, you can design your own row factory.
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
Here's an example of a :class:`dict` row factory:
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

.. doctest::
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

>>> def dict_factory(cursor, row):
... col_names = [col[0] for col in cursor.description]
... return {key: value for key, value in zip(col_names, row)}

>>> con = sqlite3.connect(":memory:")
>>> con.row_factory = dict_factory
>>> for row in con.execute("SELECT 1 AS a, 2 AS b"):
... print(row)
{'a': 1, 'b': 2}

Here's an example of a optimised :class:`~collections.namedtuple` factory:

.. testcode::

from collections import namedtuple
from functools import lru_cache

def _fields(cursor):
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
return [col[0] for col in cursor.description]

@lru_cache
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
def _make_cls(fields):
return namedtuple("Row", fields)

def NamedTupleFactory(cursor, row):
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
cls = _make_cls(_fields(cursor))
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved
return cls._make(row)
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

Example use:
erlend-aasland marked this conversation as resolved.
Show resolved Hide resolved

.. doctest::

>>> con = sqlite3.connect(":memory:")
>>> con.row_factory = NamedTupleRow
>>> cur = con.execute("SELECT 1 AS a, 2 AS b")
>>> row = cur.fetchone()
>>> row
Row(a='1', b='2')
>>> row[0] # Indexed access.
1
>>> row.b # Attribute access.
2

With some adjustments, the above recipe can be adapted to use a
:class:`~dataclasses.dataclass`, or any other custom class,
instead of a :class:`~collections.namedtuple`.


.. _sqlite3-explanation:

Explanation
Expand Down