From: Daniele Varrazzo Date: Thu, 26 Nov 2020 01:14:33 +0000 (+0000) Subject: Added a main level to the docs X-Git-Tag: 3.0.dev0~305 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=ee26c7e0a9e24264ae85e660ae3a614c1d21d6f7;p=thirdparty%2Fpsycopg.git Added a main level to the docs Docs split in several page with better visibility of titles. Also adding a sort of narrative with several cross links between topics. --- diff --git a/docs/adapt-types.rst b/docs/adapt-types.rst new file mode 100644 index 000000000..880dffa04 --- /dev/null +++ b/docs/adapt-types.rst @@ -0,0 +1,163 @@ +.. index:: + single: Adaptation + pair: Objects; Adaptation + single: Data types; Adaptation + +.. _types-adaptation: + +Adaptation between Python and PostgreSQL types +============================================== + +Many standard Python types are adapted into SQL and returned as Python +objects when a query is executed. + +The following table shows the default mapping between Python and PostgreSQL +types: + +TODO: complete table + +.. only:: html + + .. table:: + :class: data-types + + +--------------------+-------------------------+--------------------------+ + | Python | PostgreSQL | See also | + +====================+=========================+==========================+ + | `!bool` | :sql:`bool` | :ref:`adapt-bool` | + +--------------------+-------------------------+--------------------------+ + | `!float` | | :sql:`real` | :ref:`adapt-numbers` | + | | | :sql:`double` | | + +--------------------+-------------------------+ | + | | `!int` | | :sql:`smallint` | | + | | | | :sql:`integer` | | + | | | :sql:`bigint` | | + +--------------------+-------------------------+ | + | `~decimal.Decimal` | :sql:`numeric` | | + +--------------------+-------------------------+--------------------------+ + | | `!str` | | :sql:`varchar` | :ref:`adapt-string` | + | | | | :sql:`text` | | + +--------------------+-------------------------+ | + | | `!bytes` | :sql:`bytea` | | + +--------------------+-------------------------+--------------------------+ + | `!date` | :sql:`date` | :ref:`adapt-date` | + +--------------------+-------------------------+ | + | `!time` | | :sql:`time` | | + | | | :sql:`timetz` | | + +--------------------+-------------------------+ | + | `!datetime` | | :sql:`timestamp` | | + | | | :sql:`timestamptz` | | + +--------------------+-------------------------+ | + | `!timedelta` | :sql:`interval` | | + +--------------------+-------------------------+--------------------------+ + | `!list` | :sql:`ARRAY` | :ref:`adapt-list` | + +--------------------+-------------------------+--------------------------+ + | | `!tuple` | Composite types |:ref:`adapt-composite` | + | | `!namedtuple` | | | + +--------------------+-------------------------+--------------------------+ + | `!dict` | :sql:`hstore` | :ref:`adapt-hstore` | + +--------------------+-------------------------+--------------------------+ + | Psycopg's `!Range` | :sql:`range` | :ref:`adapt-range` | + +--------------------+-------------------------+--------------------------+ + | Anything\ |tm| | :sql:`json` | :ref:`adapt-json` | + +--------------------+-------------------------+--------------------------+ + | `~uuid.UUID` | :sql:`uuid` | :ref:`adapt-uuid` | + +--------------------+-------------------------+--------------------------+ + | `ipaddress` | | :sql:`inet` | :ref:`adapt-network` | + | objects | | :sql:`cidr` | | + +--------------------+-------------------------+--------------------------+ + +.. |tm| unicode:: U+2122 + + +.. index:: + pair: Boolean; Adaptation + +.. _adapt-bool: + +Booleans adaptation +------------------- + +Python `bool` values `!True` and `!False` are converted to the equivalent +`PostgreSQL boolean type`__:: + + >>> cur.execute("SELECT %s, %s", (True, False)) + # equivalent to "SELECT true, false" + +.. __: https://www.postgresql.org/docs/current/datatype-boolean.html + + +.. index:: + single: Adaptation; numbers + single: Integer; Adaptation + single: Float; Adaptation + single: Decimal; Adaptation + +.. _adapt-numbers: + +Numbers adaptation +------------------ + +Python `int` values are converted to PostgreSQL :sql:`bigint` (a.k.a. +:sql:`int8`). Note that this could create some problems: + +- Python `!int` is unbounded. If you are inserting numbers larger than 2^63 + (so your target table is `numeric`, or you'll get an overflow on + arrival...) you should convert them to `~decimal.Decimal`. + +- Certain PostgreSQL functions and operators, such a :sql:`date + int` + expect an :sql:`integer` (aka :sql:`int4`): passing them a :sql:`bigint` + may cause an error:: + + cur.execute("select current_date + %s", [1]) + # UndefinedFunction: operator does not exist: date + bigint + + In this case you should add an :sql:`::int` cast to your query or use the + `~psycopg3.types.Int4` wrapper:: + + cur.execute("select current_date + %s::int", [1]) + + cur.execute("select current_date + %s", [Int4(1)]) + + .. admonition:: TODO + + document Int* wrappers + +Python `float` values are converted to PostgreSQL :sql:`float8`. + +Python `~decimal.Decimal` values are converted to PostgreSQL :sql:`numeric`. + +On the way back, smaller types (:sql:`int2`, :sql:`int4`, :sql:`flaot4`) are +promoted to the larger Python counterpart. + +.. note:: + + Sometimes you may prefer to receive :sql:`numeric` data as `!float` + instead, for performance reason or ease of manipulation: you can configure + an adapter to :ref:`cast PostgreSQL numeric to Python float `. + This of course may imply a loss of precision. + +.. seealso:: + + - `PostgreSQL numeric types + `__ + - `Musings about numeric adaptation choices + `__ + + +.. _adapt-string: +.. _adapt-date: +.. _adapt-list: +.. _adapt-composite: +.. _adapt-hstore: +.. _adapt-range: +.. _adapt-json: +.. _adapt-uuid: +.. _adapt-network: + +TODO adaptation +---------------- + +.. admonition:: TODO + + Document the other types diff --git a/docs/adaptation.rst b/docs/adaptation.rst index bf6949e5a..b12218a2b 100644 --- a/docs/adaptation.rst +++ b/docs/adaptation.rst @@ -25,11 +25,16 @@ The `Loader` is the base object to perform the opposite operation: to read a `!bytes` string from PostgreSQL and create a Python object. `!Dumper` and `!Loader` are abstract classes: concrete classes must implement -the `~Dumper.dump()` and `~Loader.load()` method. `!psycopg3` provides +the `~Dumper.dump()` and `~Loader.load()` methods. `!psycopg3` provides implementation for several builtin Python and PostgreSQL types. +.. admonition:: TODO -.. rubric:: Dumpers and loaders configuration + Document the builtin adapters, where are they? + + +Dumpers and loaders configuration +--------------------------------- Dumpers and loaders can be registered on different scopes: globally, per `~psycopg3.Connection`, per `~psycopg3.Cursor`, so that adaptation rules can @@ -42,8 +47,14 @@ according to how they are registered (e.g. with `~Dumper.register()` or `~Dumper.register_binary()`). For most types the format is different so there will have to be two different classes. +.. admonition:: TODO + + - Example: infinity date customisation + - Example: numeric to float -.. rubric:: Dumpers and loaders life cycle + +Dumpers and loaders life cycle +------------------------------ Registering dumpers and loaders will instruct `!psycopg3` to use them in the queries to follow, in the context where they have been registered. @@ -78,6 +89,10 @@ value will be returned as a string (or bytes string for binary types). Objects involved in types adaptation ------------------------------------ +.. admonition:: TODO + + move to API section + .. autoclass:: Dumper(src, context=None) :param src: The type that will be managed by this dumper. diff --git a/docs/advanced/index.rst b/docs/advanced/index.rst new file mode 100644 index 000000000..862731499 --- /dev/null +++ b/docs/advanced/index.rst @@ -0,0 +1,10 @@ +Advanced topics +=============== + +.. toctree:: + :maxdepth: 1 + :caption: Contents: + + ../adaptation + ../copy + ../async diff --git a/docs/api/index.rst b/docs/api/index.rst new file mode 100644 index 000000000..eeae9cc45 --- /dev/null +++ b/docs/api/index.rst @@ -0,0 +1,12 @@ +``psycopg3`` API +================ + +.. toctree:: + :maxdepth: 1 + :caption: Contents: + + ../connection + ../cursor + ../sql + ../errors + ../pq diff --git a/docs/async.rst b/docs/async.rst new file mode 100644 index 000000000..12e3ff1fe --- /dev/null +++ b/docs/async.rst @@ -0,0 +1,161 @@ +.. currentmodule:: psycopg3 + +.. index:: asyncio + +Async operations +================ + +psycopg3 `~Connection` and `~Cursor` have counterparts `~AsyncConnection` and +`~AsyncCursor` supporting an `asyncio` interface. + +The design of the asynchronous objects is pretty much the same of the sync +ones: in order to use them you will only have to scatter the ``await`` keyword +here and there. + +.. code:: python + + async with await psycopg3.AsyncConnection.connect( + "dbname=test user=postgres") as aconn: + async with await aconn.cursor() as acur: + await acur.execute( + "INSERT INTO test (num, data) VALUES (%s, %s)", + (100, "abc'def")) + await acur.execute("SELECT * FROM test") + await acur.fetchone() + # will return (1, 100, "abc'def") + async for record in acur: + print(record) + + +.. index:: with + +.. _async-with: + +``with`` async connections and cursors +-------------------------------------- + +As seen in :ref:`the basic usage `, connections and cursors can act as +context managers, so you can run: + +.. code:: python + + with psycopg3.connect("dbname=test user=postgres") as conn: + with conn.cursor() as cur: + cur.execute(...) + # the cursor is closed upon leaving the context + # the transaction is committed, the connection closed + +For asynchronous connections and cursor it's *almost* what you'd expect, but +not quite. Please note that `~Connection.connect()` and `~Connection.cursor()` +*don't return a context*: they are both factory methods which return *an +object which can be used as a context*. That's because there are several use +cases where it's useful to handle the object manually and `!close()` them when +required. + +As a consequence you cannot use `!async with connect()`: you have to do it in +two steps instead, as in + +.. code:: python + + aconn = await psycopg3.AsyncConnection.connect(): + async with aconn: + cur = await aconn.cursor() + async with cur: + await cur.execute(...) + +which can be condensed as: + +.. code:: python + + async with await psycopg3.AsyncConnection.connect() as aconn: + async with await aconn.cursor() as cur: + await cur.execute(...) + +...but no less than that: you still need to do the double async thing. + + + +.. index:: + pair: Asynchronous; Notifications + pair: LISTEN; SQL command + pair: NOTIFY; SQL command + +.. _async-notify: + +Asynchronous notifications +-------------------------- + +Psycopg allows asynchronous interaction with other database sessions using the +facilities offered by PostgreSQL commands |LISTEN|_ and |NOTIFY|_. Please +refer to the PostgreSQL documentation for examples about how to use this form +of communication. + +.. |LISTEN| replace:: :sql:`LISTEN` +.. _LISTEN: https://www.postgresql.org/docs/current/sql-listen.html +.. |NOTIFY| replace:: :sql:`NOTIFY` +.. _NOTIFY: https://www.postgresql.org/docs/current/sql-notify.html + +Because of the way sessions interact with notifications (see |NOTIFY|_ +documentation), you should keep the connection in `~Connection.autocommit` +mode if you wish to receive or send notifications in a timely manner. + +Notifications are received as instances of `Notify`. If you are reserving a +connection only to receive notifications, the simplest way is to consume the +`Connection.notifies` generator. The generator can be stopped using +``close()``. + +.. note:: + + You don't need an `AsyncConnection` to handle notifications: a normal + blocking `Connection` is perfectly valid. + +The following example will print notifications and stop when one containing +the ``stop`` message is received. + +.. code:: python + + import psycopg3 + conn = psycopg3.connect("", autocommit=True) + conn.cursor().execute("LISTEN mychan") + gen = conn.notifies() + for notify in gen: + print(notify) + if notify.payload == "stop": + gen.close() + print("there, I stopped") + +If you run some :sql:`NOTIFY` in a :program:`psql` session: + +.. code:: psql + + =# notify mychan, 'hello'; + NOTIFY + =# notify mychan, 'hey'; + NOTIFY + =# notify mychan, 'stop'; + NOTIFY + +You may get output from the Python process such as:: + + Notify(channel='mychan', payload='hello', pid=961823) + Notify(channel='mychan', payload='hey', pid=961823) + Notify(channel='mychan', payload='stop', pid=961823) + there, I stopped + +Alternatively, you can use `~Connection.add_notify_handler()` to register a +callback function, which will be invoked whenever a notification is received, +during the normal query processing; you will be then able to use the +connection normally. Please note that in this case notifications will not be +received immediately, but only during a connection operation, such as a query. + +.. code:: python + + conn.add_notify_handler(lambda n: print(f"got this: {n}")) + + # meanwhile in psql... + # =# notify mychan, 'hey'; + # NOTIFY + + print(conn.cursor().execute("select 1").fetchone()) + # got this: Notify(channel='mychan', payload='hey', pid=961823) + # (1,) diff --git a/docs/basic/index.rst b/docs/basic/index.rst new file mode 100644 index 000000000..ef08a0a9f --- /dev/null +++ b/docs/basic/index.rst @@ -0,0 +1,21 @@ + +Getting started with ``psycopg3`` +================================= + +.. toctree:: + :maxdepth: 1 + :caption: Contents: + + ../install + ../usage + ../params + ../adapt-types + ../transactions + + +Indices and tables +------------------ + +* :ref:`genindex` +* :ref:`modindex` +* :ref:`search` diff --git a/docs/conf.py b/docs/conf.py index bbf7bc1ec..63ba5e1e9 100644 --- a/docs/conf.py +++ b/docs/conf.py @@ -64,7 +64,10 @@ else: html_css_files = ["psycopg.css"] # The name of the Pygments (syntax highlighting) style to use. -pygments_style = "default" +# Some that I've check don't suck: +# default lovelace tango algol_nu +# list: from pygments.styles import STYLE_MAP; print(sorted(STYLE_MAP.keys())) +pygments_style = "tango" # The theme to use for HTML and HTML Help pages. See the documentation for # a list of builtin themes. diff --git a/docs/connection.rst b/docs/connection.rst index 962b1fe3d..b05df06a2 100644 --- a/docs/connection.rst +++ b/docs/connection.rst @@ -1,8 +1,8 @@ +.. currentmodule:: psycopg3 + Connection classes ================== -.. currentmodule:: psycopg3 - The `Connection` and `AsyncConnection` classes are the main wrappers for a PostgreSQL database session. You can imagine them similar to a :program:`psql` session. @@ -50,7 +50,7 @@ The `!Connection` class .. automethod:: close - .. note:: You can use :ref:`with connect(): ...` to + .. note:: You can use :ref:`with connect(): ...` to close the connection automatically when the block is exited. .. autoattribute:: closed @@ -58,7 +58,7 @@ The `!Connection` class .. automethod:: cursor - .. note:: You can use :ref:`with conn.cursor(): ...` + .. note:: You can use :ref:`with conn.cursor(): ...` to close the cursor automatically when the block is exited. @@ -134,13 +134,13 @@ The `!AsyncConnection` class .. note:: You can use ``async with`` to close the connection automatically when the block is exited, but be careful about - the async quirkness: see :ref:`with-statement` for details. + the async quirkness: see :ref:`async-with` for details. .. automethod:: cursor .. note:: You can use ``async with`` to close the cursor automatically when the block is exited, but be careful about - the async quirkness: see :ref:`with-statement` for details. + the async quirkness: see :ref:`async-with` for details. .. automethod:: commit .. automethod:: rollback diff --git a/docs/copy.rst b/docs/copy.rst new file mode 100644 index 000000000..dcbe18722 --- /dev/null +++ b/docs/copy.rst @@ -0,0 +1,70 @@ +.. index:: + pair: COPY; SQL command + +.. _copy: + +Using COPY TO and COPY FROM +=========================== + +`psycopg3` allows to operate with `PostgreSQL COPY protocol`__. :sql:`COPY` is +one of the most efficient ways to load data into the database (and to modify +it, with some SQL creativity). + +.. __: https://www.postgresql.org/docs/current/sql-copy.html + +Using `!psycopg3` you can do three things: + +- loading data into the database row-by-row, from a stream of Python objects; +- loading data into the database block-by-block, with data already formatted in + a way suitable for :sql:`COPY FROM`; +- reading data from the database block-by-block, with data emitted by a + :sql:`COPY TO` statement. + +The missing quadrant, copying data from the database row-by-row, is not +covered by COPY because that's pretty much normal querying, and :sql:`COPY TO` +doesn't offer enough metadata to decode the data to Python objects. + +The first option is the most powerful, because it allows to load data into the +database from any Python iterable (a list of tuple, or any iterable of +sequences): the Python values are adapted as they would be in normal querying. +To perform such operation use a :sql:`COPY [table] FROM STDIN` with +`Cursor.copy()` and use `~Copy.write_row()` on the resulting object in a +``with`` block. On exiting the block the operation will be concluded: + +.. code:: python + + with cursor.copy("COPY table_name (col1, col2) FROM STDIN") as copy: + for row in source: + copy.write_row(row) + +If an exception is raised inside the block, the operation is interrupted and +the records inserted so far discarded. + +If data is already formatted in a way suitable for copy (for instance because +it is coming from a file resulting from a previous `COPY TO` operation) it can +be loaded using `Copy.write()` instead. + +In order to read data in :sql:`COPY` format you can use a :sql:`COPY TO +STDOUT` statement and iterate over the resulting `Copy` object, which will +produce `!bytes`: + +.. code:: python + + with open("data.out", "wb") as f: + with cursor.copy("COPY table_name TO STDOUT") as copy: + for data in copy: + f.write(data) + +Asynchronous operations are supported using the same patterns on an +`AsyncConnection`. For instance, if `!f` is an object supporting an +asynchronous `!read()` method returning :sql:`COPY` data, a fully-async copy +operation could be: + +.. code:: python + + async with cursor.copy("COPY data FROM STDIN") as copy: + while data := await f.read() + await copy.write(data) + +Binary data can be produced and consumed using :sql:`FORMAT BINARY` in the +:sql:`COPY` command: see :ref:`binary-data` for details and limitations. diff --git a/docs/cursor.rst b/docs/cursor.rst index 92d43bc48..04cfea7ef 100644 --- a/docs/cursor.rst +++ b/docs/cursor.rst @@ -1,8 +1,8 @@ +.. currentmodule:: psycopg3 + Cursor classes ============== -.. currentmodule:: psycopg3 - The `Cursor` and `AsyncCursor` classes are the main objects to send commands to a PostgreSQL database session. They are normally created by the connection's `~Connection.cursor()` method. @@ -38,7 +38,7 @@ The `!Cursor` class .. automethod:: close - .. note:: you can use :ref:`with conn.cursor(): ...` + .. note:: you can use :ref:`with conn.cursor(): ...` to close the cursor automatically when the block is exited. .. autoattribute:: closed @@ -142,7 +142,7 @@ The `!AsyncCursor` class .. note:: you can use ``async with`` to close the cursor automatically when the block is exited, but be careful about - the async quirkness: see :ref:`with-statement` for details. + the async quirkness: see :ref:`async-with` for details. .. automethod:: execute(query: Query, params: Optional[Args]=None) -> AsyncCursor .. automethod:: executemany(query: Query, params_seq: Sequence[Args]) diff --git a/docs/errors.rst b/docs/errors.rst index 59d9900e9..3c6d8821a 100644 --- a/docs/errors.rst +++ b/docs/errors.rst @@ -1,5 +1,5 @@ -`psycopg3.errors` -- package exceptions -======================================= +`errors` -- package exceptions +============================== .. index:: single: Error; Class @@ -116,7 +116,7 @@ the documentation`__, converted to CamelCase: e.g. the error 22012, There is a handful of exception, required for disambiguate clashes: please refer to the table below for all the classes defined. -.. __: https://www.postgresql.org/docs/current/static/errcodes-appendix.html#ERRCODES-TABLE +.. __: https://www.postgresql.org/docs/current/errcodes-appendix.html#ERRCODES-TABLE Every exception class is a subclass of one of the :ref:`standard DB-API exception ` and expose the `~Error` interface. diff --git a/docs/from_pg2.rst b/docs/from_pg2.rst index bcf99869d..a954e17d6 100644 --- a/docs/from_pg2.rst +++ b/docs/from_pg2.rst @@ -1,8 +1,8 @@ .. index:: pair: psycopg2; Differences -Differences from psycopg2 -========================= +Differences from ``psycopg2`` +============================= `!psycopg3` uses the common DBAPI structure of many other database adapter and tries to behave as close as possible to `!psycopg2`. There are however a few @@ -53,6 +53,19 @@ works for an empty list, whereas an empty tuple would have resulted in an error. +.. _diff-numbers: + +``int`` is stricter +------------------- + +Operations involving numbers may fail if the number is passed to a function or +operator and PostgreSQL expects a :sql:`integer` and not a :sql:`bigint`. +Examples may be :sql:`date + int`, :sql:`jsonb -> int`. In this case you +should use an :sql:`::int` cast or the `psycopg3.types.Int4` wrapper. + + +.. _diff-adapt: + Different adaptation system --------------------------- @@ -64,6 +77,8 @@ Builtin data types should work as expected; if you have wrapped a custom data type you should check the :ref:`adaptation` topic. +.. _diff-copy: + Copy is no more file-based -------------------------- @@ -79,26 +94,36 @@ usage pattern also enables :sql:`COPY` to be used in async interactions. See :ref:`copy` for the details. -Other differences ------------------ +.. _diff-with: + +``with`` connection +------------------- + +When the connection is used as context manager, at the end of the context +the connection will be closed. In psycopg2 only the transaction is closed, +so a connection can be used in several contexts, but the behaviour is +surprising for people used to several other Python classes wrapping +resources, such as files. -- When the connection is used as context manager, at the end of the context - the connection will be closed. In psycopg2 only the transaction is closed, - so a connection can be used in several contexts, but the behaviour is - surprising for people used to several other Python classes wrapping - resources, such as files. -- `cursor.callproc()` is not implemented. The method has a simplistic - semantic which doesn't account for PostgreSQL positional parameters, - procedures, set-returning functions. Use a normal - `~psycopg3.Cursor.execute()` with :sql:`SELECT function_name(...)` or - :sql:`CALL procedure_name(...)` instead. +.. _diff-callproc: + +``callproc()`` is gone +---------------------- + +`cursor.callproc()` is not implemented. The method has a simplistic +semantic which doesn't account for PostgreSQL positional parameters, +procedures, set-returning functions. Use a normal +`~psycopg3.Cursor.execute()` with :sql:`SELECT function_name(...)` or +:sql:`CALL procedure_name(...)` instead. What's new in psycopg3 -====================== +---------------------- + +.. admonition:: TODO -TODO: to be completed + to be completed - `asyncio` support. - Several data types are adapted out-of-the-box: uuid, network, range, bytea, diff --git a/docs/index.rst b/docs/index.rst index db7305616..c1bad2e32 100644 --- a/docs/index.rst +++ b/docs/index.rst @@ -16,17 +16,12 @@ the COPY support. .. __: https://www.python.org/dev/peps/pep-0249/ .. toctree:: - :maxdepth: 2 + :maxdepth: 1 :caption: Contents: - install - usage - connection - cursor - adaptation - sql - errors - pq + basic/index + advanced/index + api/index from_pg2 diff --git a/docs/install.rst b/docs/install.rst index 85202f29d..45d631eaf 100644 --- a/docs/install.rst +++ b/docs/install.rst @@ -35,6 +35,10 @@ some though: Proper installation ------------------- +.. admonition:: TODO + + "proper" is scary... bettern name? + Proper install means obtaining a performing and maintainable library. The library will include a performing C module and will be bound to the system libpq, so that system upgrade of libraries will upgrade the library used by @@ -76,3 +80,13 @@ need:: If you are not able to fulfill this requirement please follow the `quick install`_. + + + +``psycopg3`` and the ``libpq`` +------------------------------ + +.. admonition:: TODO + + describe the relations between psycopg and the libpq and the binding + choices diff --git a/docs/params.rst b/docs/params.rst new file mode 100644 index 000000000..bf0b901c2 --- /dev/null +++ b/docs/params.rst @@ -0,0 +1,200 @@ +.. currentmodule:: psycopg3 + +.. index:: + pair: Query; Parameters + +.. _query-parameters: + +Passing parameters to SQL queries +================================= + +Most of the times, writing a program you will have to mix bits of SQL +statements with values provided by the rest of the program: + +.. code:: + + SELECT some, fields FROM some_table WHERE id = ... + +:sql:`id` equals what? Probably you will have a Python value you are looking +for. + + +``execute()`` arguments +----------------------- + +Passing parameters to a SQL statement happens in functions such as +`Cursor.execute()` by using ``%s`` placeholders in the SQL statement, and +passing a sequence of values as the second argument of the function. For +example the Python function call: + +.. code:: python + + cur.execute(""" + INSERT INTO some_table (an_int, a_date, a_string) + VALUES (%s, %s, %s); + """, + (10, datetime.date(2020, 11, 18), "O'Reilly")) + +is *roughly* equivalent to the SQL command: + +.. code-block:: sql + + INSERT INTO some_table (an_int, a_date, a_string) + VALUES (10, '2020-11-18', 'O''Reilly'); + +Note that the parameters will not be really merged to the query: query and the +parameters are sent to the server separately: see :ref:`server-side-binding` +for details. + +Named arguments are supported too using :samp:`%({name})s` placeholders in the +query and specifying the values into a mapping. Using named arguments allows +to specify the values in any order and to repeat the same value in several +places in the query:: + + cur.execute(""" + INSERT INTO some_table (an_int, a_date, another_date, a_string) + VALUES (%(int)s, %(date)s, %(date)s, %(str)s); + """, + {'int': 10, 'str': "O'Reilly", 'date': datetime.date(2020, 11, 18)}) + +Using characters ``%``, ``(``, ``)`` in the argument names is not supported. + +When parameters are used, in order to include a literal ``%`` in the query you +can use the ``%%`` string:: + + cur.execute("SELECT (%s % 2) = 0 AS even", (10,)) # WRONG + cur.execute("SELECT (%s %% 2) = 0 AS even", (10,)) # correct + +While the mechanism resembles regular Python strings manipulation, there are a +few subtle differences you should care about when passing parameters to a +query. + +- The Python string operator ``%`` *must not be used*: the `~cursor.execute()` + method accepts a tuple or dictionary of values as second parameter. + |sql-warn|__: + + .. |sql-warn| replace:: **Never** use ``%`` or ``+`` to merge values + into queries + + .. code:: python + + cur.execute("INSERT INTO numbers VALUES (%s, %s)" % (10, 20)) # WRONG + cur.execute("INSERT INTO numbers VALUES (%s, %s)", (10, 20)) # correct + + .. __: sql-injection_ + +- For positional variables binding, *the second argument must always be a + sequence*, even if it contains a single variable (remember that Python + requires a comma to create a single element tuple):: + + cur.execute("INSERT INTO foo VALUES (%s)", "bar") # WRONG + cur.execute("INSERT INTO foo VALUES (%s)", ("bar")) # WRONG + cur.execute("INSERT INTO foo VALUES (%s)", ("bar",)) # correct + cur.execute("INSERT INTO foo VALUES (%s)", ["bar"]) # correct + +- The placeholder *must not be quoted*. Psycopg will add quotes where needed:: + + cur.execute("INSERT INTO numbers VALUES ('%s')", (10,)) # WRONG + cur.execute("INSERT INTO numbers VALUES (%s)", (10,)) # correct + +- The variables placeholder *must always be a* ``%s``, even if a different + placeholder (such as a ``%d`` for integers or ``%f`` for floats) may look + more appropriate for tye type. Another placeholder you can use is ``%b``, to + :ref:`adapt the object to binary type `:: + + cur.execute("INSERT INTO numbers VALUES (%d)", (10,)) # WRONG + cur.execute("INSERT INTO numbers VALUES (%s)", (10,)) # correct + +- Only query values should be bound via this method: it shouldn't be used to + merge table or field names to the query. If you need to generate SQL queries + dynamically (for instance choosing a table name at runtime) you can use the + functionalities provided in the `psycopg3.sql` module:: + + cur.execute("INSERT INTO %s VALUES (%s)", ('numbers', 10)) # WRONG + cur.execute( # correct + SQL("INSERT INTO {} VALUES (%s)").format(Identifier('numbers')), + (10,)) + + +.. index:: Security, SQL injection + +.. _sql-injection: + +Danger: SQL injection +--------------------- + +The SQL representation of many data types is often different from their Python +string representation. The typical example is with single quotes in strings: +in SQL single quotes are used as string literal delimiters, so the ones +appearing inside the string itself must be escaped, whereas in Python single +quotes can be left unescaped if the string is delimited by double quotes. + +Because of the difference, sometimes subtle, between the data types +representations, a naïve approach to query strings composition, such as using +Python strings concatenation, is a recipe for *terrible* problems:: + + SQL = "INSERT INTO authors (name) VALUES ('%s')" # NEVER DO THIS + data = ("O'Reilly", ) + cur.execute(SQL % data) # THIS WILL FAIL MISERABLY + # SyntaxError: syntax error at or near "Reilly" + +If the variables containing the data to send to the database come from an +untrusted source (such as data coming from a form on a web site) an attacker +could easily craft a malformed string, either gaining access to unauthorized +data or performing destructive operations on the database. This form of attack +is called `SQL injection`_ and is known to be one of the most widespread forms +of attack to database systems. Before continuing, please print `this page`__ +as a memo and hang it onto your desk. + +.. _SQL injection: https://en.wikipedia.org/wiki/SQL_injection +.. __: https://xkcd.com/327/ + +Psycopg can :ref:`automatically convert Python objects to SQL +values`: using this feature your code will be more robust +and reliable. We must stress this point: + +.. warning:: + + - Don't merge manually values to a query: hackers from a foreign country + will break into your computer and steal not only your disks, but also + your cds, leaving you only with the three most embarrassing records you + ever bought. On tape. + + - If you use the ``%`` operator to merge values to a query, con artists + will seduce your cat, who will run away taking your credit card + and your sunglasses with them. + + - If you use ``+`` to merge a textual value to a string, bad guys in + balaclava will find their way to your fridge, drink all your beer, and + leave your toilet sit up and your toilet paper in the wrong orientation. + + - You don't want to merge manually values to a query: :ref:`use the + provided methods ` instead. + +The correct way to pass variables in a SQL command is using the second +argument of the `Cursor.execute()` method:: + + SQL = "INSERT INTO authors (name) VALUES (%s)" # Note: no quotes + data = ("O'Reilly", ) + cur.execute(SQL, data) # Note: no % operator + + +.. seealso:: + + Now that you know how to pass parameters to queries, you can take a look + at :ref:`how psycopg3 converts data types `. + + +.. index:: + pair: Binary; Parameters + +.. _binary-data: + +Binary parameters and results +----------------------------- + +.. admonition:: TODO + + - pass parameters in binary with ``%b`` + - return parameters in binary with `!cursor(format=BINARY)` + diff --git a/docs/pq.rst b/docs/pq.rst index bc6058ff1..9b500f4d2 100644 --- a/docs/pq.rst +++ b/docs/pq.rst @@ -1,5 +1,5 @@ -`psycopg3.pq` -- Libpq wrapper module -===================================== +`pq` -- Libpq wrapper module +============================ .. index:: single: libpq @@ -63,6 +63,10 @@ Module content .. autofunction:: version + .. admonition:: TODO + + Document pg10 quirk. + .. seealso:: the :pq:`PQlibVersion()` function diff --git a/docs/sql.rst b/docs/sql.rst index 9748a14f2..aa9c7bd9c 100644 --- a/docs/sql.rst +++ b/docs/sql.rst @@ -1,5 +1,5 @@ -`psycopg3.sql` -- SQL string composition -======================================== +`sql` -- SQL string composition +=============================== .. index:: double: Binding; Client-Side diff --git a/docs/transactions.rst b/docs/transactions.rst new file mode 100644 index 000000000..ae7a0769a --- /dev/null +++ b/docs/transactions.rst @@ -0,0 +1,143 @@ +.. currentmodule:: psycopg3 + +.. index:: Transactions management +.. index:: InFailedSqlTransaction +.. index:: idle in transaction + +.. _transactions: + +Transaction management +====================== + +`!psycopg3` has a behaviour that may result surprising compared to +:program:`psql`: by default, any database operation will start a new +transaction. As a consequence, changes made by any cursor of the connection +will not be visible until `Connection.commit()` is called, and will be +discarded by `Connection.rollback()`. The following operation on the same +connection will start a new transaction. + +If a database operation fails, the server will refuse further commands, until +a `~rollback()` is called. + +.. hint:: + + If a database operation fails with an error message such as + *InFailedSqlTransaction: current transaction is aborted, commands ignored + until end of transaction block*, it means that **a previous operation + failed** and the database session is in a state of error. You need to call + `!rollback()` if you want to keep on using the same connection. + + +.. _autocommit: + +Autocommit transactions +----------------------- + +The manual commit requirement can be suspended using `~Connection.autocommit`, +either as connection attribute or as `~psycopg3.Connection.connect()` +parameter. This may be required to run operations that cannot be executed +inside a transaction, such as :sql:`CREATE DATABASE`, :sql:`VACUUM`, +:sql:`CALL` on `stored procedures`__ using transaction control. + +.. __: https://www.postgresql.org/docs/current/xproc.html + +.. warning:: + + By default even a simple :sql:`SELECT` will start a transaction: in + long-running programs, if no further action is taken, the session will + remain *idle in transaction*, an undesirable condition for several + reasons (locks are held by the session, tables bloat...). For long lived + scripts, either make sure to terminate a transaction as soon as possible or + use an `~Connection.autocommit` connection. + + +.. _transaction-block: + +Transaction blocks +------------------ + +A more transparent way to make sure that transactions are finalised at the +right time is to use ``with`` `Connection.transaction()` to create a +transaction block. When the block is entered a transaction is started; when +leaving the block the transaction is committed, or it is rolled back if an +exception is raised inside the block. + +For instance, an hypothetical but extremely secure bank may have the following +code to avoid that no accident between the following two lines leaves the +accounts unbalanced: + +.. code:: python + + with conn.transaction(): + move_money(conn, account1, -100) + move_money(conn, account2, +100) + + # The transaction is now committed + +But because the bank is, like, *extremely secure*, they also verify that no +account goes negative: + +.. code:: python + + def move_money(conn, account, amount): + new_balance = add_to_balance(conn, account, amount) + if new_balance < 0: + raise ValueError("account balance cannot go negative") + +In case this function raises an exception, be it the `!ValueError` in the +example or any other exception expected or not, the transaction will be rolled +back, and the exception will propagate out of the `with` block, further down +the call stack. + +Transaction blocks can also be nested (internal transaction blocks are +implemented using SAVEPOINT__): an exception raised inside an inner block +has a chance of being handled and not completely fail outer operations. The +following is an example where a series of operations interact with the +database: operations are allowed to fail, plus we also want to store the +number of operations successfully processed. + +.. __: https://www.postgresql.org/docs/current/sql-savepoint.html + +.. code:: python + + with conn.transaction() as tx1: + num_ok = 0 + for operation in operations: + try: + with conn.transaction() as tx2: + unreliable_operation(conn, operation) + except Exception: + logger.exception(f"{operation} failed") + else: + num_ok += 1 + + save_number_of_successes(conn, num_ok) + +If `!unreliable_operation()` causes an error, including an operation causing a +database error, all its changes will be reverted. The exception bubbles up +outside the block: in the example it is intercepted by the ``try`` so that the +loop can complete. The outermost block is unaffected (unless other errors +happen there). + +You can also write code to explicitly roll back any currently active +transaction block, by raising the `Rollback` exception. The exception "jumps" +to the end of a transaction block, rolling back its transaction but allowing +the program execution to continue from there. By default the exception rolls +back the innermost transaction block, but any current block can be specified +as the target. In the following example, an hypothetical `!CancelCommand` +may stop the processing and cancel any operation previously performed, +but not entirely committed yet. + +.. code:: python + + from psycopg3 import Rollback + + with conn.transaction() as outer_tx: + for command in commands(): + with conn.transaction() as inner_tx: + if isinstance(command, CancelCommand): + raise Rollback(outer_tx) + process_command(command) + + # If `Rollback` is raised, it would propagate only up to this block, + # and the program would continue from here with no exception. diff --git a/docs/usage.rst b/docs/usage.rst index 85f3433a9..2e2e5965f 100644 --- a/docs/usage.rst +++ b/docs/usage.rst @@ -1,17 +1,22 @@ .. currentmodule:: psycopg3 +Basic module usage +================== + +The basic Psycopg usage is common to all the database adapters implementing +the `DB API`__ protocol. Other database adapters, such as the builtin +`sqlite3` or `psycopg2`, have roughly the same pattern of interaction. + .. index:: pair: Example; Usage .. _usage: -Basic module usage -================== +Main objects in ``psycopg3`` +---------------------------- -The basic Psycopg usage is common to all the database adapters implementing -the `DB API`__ protocol. Here is an interactive session showing some of the -basic commands: +Here is an interactive session showing some of the basic commands: .. __: https://www.python.org/dev/peps/pep-0249/ @@ -20,58 +25,44 @@ basic commands: import psycopg3 # Connect to an existing database - conn = psycopg3.connect("dbname=test user=postgres") - - # Open a cursor to perform database operations - cur = conn.cursor() - - # Execute a command: this creates a new table - cur.execute(""" - CREATE TABLE test ( - id serial PRIMARY KEY, - num integer, - data text) - """) - - # Pass data to fill a query placeholders and let Psycopg perform - # the correct conversion (no SQL injections!) - cur.execute( - "INSERT INTO test (num, data) VALUES (%s, %s)", - (100, "abc'def")) - - # Query the database and obtain data as Python objects. - cur.execute("SELECT * FROM test") - cur.fetchone() - # will return (1, 100, "abc'def") - - # You can use `cur.fetchmany()`, `cur.fetchall()` to return a list - # of several records, or even iterate on the cursor - for record in cur: - print(record) - - # Make the changes to the database persistent - conn.commit() + with psycopg3.connect("dbname=test user=postgres") as conn: - # Close communication with the database - cur.close() - conn.close() + # Open a cursor to perform database operations + with conn.cursor() as cur: + # Execute a command: this creates a new table + cur.execute(""" + CREATE TABLE test ( + id serial PRIMARY KEY, + num integer, + data text) + """) -Note that the `cursor.execute()` method returns the cursor itself, so the -`fetch*()` methods can be appended right after it. + # Pass data to fill a query placeholders and let Psycopg perform + # the correct conversion (no SQL injections!) + cur.execute( + "INSERT INTO test (num, data) VALUES (%s, %s)", + (100, "abc'def")) -.. code:: python + # Query the database and obtain data as Python objects. + cur.execute("SELECT * FROM test") + cur.fetchone() + # will return (1, 100, "abc'def") - cur.execute("SELECT * FROM test").fetchone() + # You can use `cur.fetchmany()`, `cur.fetchall()` to return a list + # of several records, or even iterate on the cursor + for record in cur: + print(record) - for record in cur.execute("SELECT * FROM test"): - print(record) + # Make the changes to the database persistent + conn.commit() -The main entry points of `!psycopg3` are: +In the example you can see some of the main objects and methods and how they +relate to each other: -- The function `connect()` creates a new database session and - returns a new `connection` instance. `AsyncConnection.connect()` +- The function `~Connection.connect()` creates a new database session and + returns a new `Connection` instance. `AsyncConnection.connect()` creates an `asyncio` connection instead. - The `~Connection` class encapsulates a database session. It allows to: @@ -90,621 +81,15 @@ The main entry points of `!psycopg3` are: - retrieve data from the database, iterating on the cursor or using methods such as `~Cursor.fetchone()`, `~Cursor.fetchmany()`, `~Cursor.fetchall()`. +- Using these objects as context managers (i.e. using ``with``) will make sure + to close them and free their resources at the end of the block (notice that + `this is different from psycopg2`. -.. index:: with - -.. _with-statement: - -``with`` connections and cursors --------------------------------- - -Connections and cursors act as context managers, so you can run: - -.. code:: python - - with psycopg3.connect("dbname=test user=postgres") as conn: - with conn.cursor() as cur: - cur.execute( - "INSERT INTO test (num, data) VALUES (%s, %s)", - (100, "abc'def")) - cur.execute("SELECT * FROM test").fetchone() - # will return (1, 100, "abc'def") - - # the cursor is closed upon leaving the context - - # the transaction is committed on successful exit of the context - # and the connection closed - -For asynchronous connections and cursor it's *almost* what you'd expect, but -not quite. Please note that `!connect()` and `!cursor()` *don't return a -context*: they are both factory methods which return *an object which can be -used as a context*. So you cannot use ``async with connect()``: you have to do -it in two steps instead, as in - -.. code:: python - - aconn = await psycopg3.AsyncConnection.connect(): - async with aconn: - cur = await aconn.cursor() - async with cur: - await cur.execute(...) - -which can be condensed as: - -.. code:: python - - async with (await psycopg3.AsyncConnection.connect()) as aconn: - async with (await aconn.cursor()) as cur: - await cur.execute(...) - -...but no less than that: you still need to do the double async thing. - - -.. index:: - pair: Query; Parameters - -.. _query-parameters: - -Passing parameters to SQL queries -================================= - -``psycopg3`` converts Python variables to SQL values using their types: the -Python type determines the function used to convert the object into a string -representation suitable for PostgreSQL. Many standard Python types are -`adapted out of the box`__ to the correct SQL representation. - -.. __: python-types-adaptation_ - -Passing parameters to an SQL statement happens in functions such as -`Cursor.execute()` by using ``%s`` placeholders in the SQL statement, and -passing a sequence of values as the second argument of the function. For -example the Python function call:: - - >>> cur.execute(""" - ... INSERT INTO some_table (an_int, a_date, a_string) - ... VALUES (%s, %s, %s); - ... """, - ... (10, datetime.date(2020, 11, 18), "O'Reilly")) - -is roughly equivalent to the SQL command: - -.. code-block:: sql - - INSERT INTO some_table (an_int, a_date, a_string) - VALUES (10, '2020-11-18', 'O''Reilly'); - -Note that the parameters will not be really merged to the query: query and the -parameters are sent to the server separately: see :ref:`server-side-binding` -for details. - -Named arguments are supported too using :samp:`%({name})s` placeholders in the -query and specifying the values into a mapping. Using named arguments allows -to specify the values in any order and to repeat the same value in several -places in the query:: - - >>> cur.execute(""" - ... INSERT INTO some_table (an_int, a_date, another_date, a_string) - ... VALUES (%(int)s, %(date)s, %(date)s, %(str)s); - ... """, - ... {'int': 10, 'str': "O'Reilly", 'date': datetime.date(2020, 11, 18)}) - -Using characters ``%``, ``(``, ``)`` in the argument names is not supported. - -When parameters are used, in order to include a literal ``%`` in the query you -can use the ``%%`` string:: - - >>> cur.execute("SELECT (%s % 2) = 0 AS even", (10,)) # WRONG - >>> cur.execute("SELECT (%s %% 2) = 0 AS even", (10,)) # correct - -While the mechanism resembles regular Python strings manipulation, there are a -few subtle differences you should care about when passing parameters to a -query. - -- The Python string operator ``%`` *must not be used*: the `~cursor.execute()` - method accepts a tuple or dictionary of values as second parameter. - |sql-warn|__: - - .. |sql-warn| replace:: **Never** use ``%`` or ``+`` to merge values - into queries - - .. __: sql-injection_ - - >>> cur.execute("INSERT INTO numbers VALUES (%s, %s)" % (10, 20)) # WRONG - >>> cur.execute("INSERT INTO numbers VALUES (%s, %s)", (10, 20)) # correct - -- For positional variables binding, *the second argument must always be a - sequence*, even if it contains a single variable (remember that Python - requires a comma to create a single element tuple):: - - >>> cur.execute("INSERT INTO foo VALUES (%s)", "bar") # WRONG - >>> cur.execute("INSERT INTO foo VALUES (%s)", ("bar")) # WRONG - >>> cur.execute("INSERT INTO foo VALUES (%s)", ("bar",)) # correct - >>> cur.execute("INSERT INTO foo VALUES (%s)", ["bar"]) # correct - -- The placeholder *must not be quoted*. Psycopg will add quotes where needed:: - - >>> cur.execute("INSERT INTO numbers VALUES ('%s')", (10,)) # WRONG - >>> cur.execute("INSERT INTO numbers VALUES (%s)", (10,)) # correct - -- The variables placeholder *must always be a* ``%s``, even if a different - placeholder (such as a ``%d`` for integers or ``%f`` for floats) may look - more appropriate. Another placeholder used is ``%b``, to :ref:`adapt the - object to binary type `:: - - >>> cur.execute("INSERT INTO numbers VALUES (%d)", (10,)) # WRONG - >>> cur.execute("INSERT INTO numbers VALUES (%s)", (10,)) # correct - -- Only query values should be bound via this method: it shouldn't be used to - merge table or field names to the query. If you need to generate dynamically - SQL queries (for instance choosing dynamically a table name) you can use the - facilities provided by the `psycopg3.sql` module:: - - >>> cur.execute("INSERT INTO %s VALUES (%s)", ('numbers', 10)) # WRONG - >>> cur.execute( # correct - ... SQL("INSERT INTO {} VALUES (%s)").format(Identifier('numbers')), - ... (10,)) - - -.. index:: Security, SQL injection - -.. _sql-injection: - -The problem with the query parameters -------------------------------------- - -The SQL representation of many data types is often different from their Python -string representation. The typical example is with single quotes in strings: -in SQL single quotes are used as string literal delimiters, so the ones -appearing inside the string itself must be escaped, whereas in Python single -quotes can be left unescaped if the string is delimited by double quotes. - -Because of the difference, sometime subtle, between the data types -representations, a naïve approach to query strings composition, such as using -Python strings concatenation, is a recipe for *terrible* problems:: - - >>> SQL = "INSERT INTO authors (name) VALUES ('%s')" # NEVER DO THIS - >>> data = ("O'Reilly", ) - >>> cur.execute(SQL % data) # THIS WILL FAIL MISERABLY - SyntaxError: syntax error at or near "Reilly" - -If the variables containing the data to send to the database come from an -untrusted source (such as a form published on a web site) an attacker could -easily craft a malformed string, either gaining access to unauthorized data or -performing destructive operations on the database. This form of attack is -called `SQL injection`_ and is known to be one of the most widespread forms of -attack to database servers. Before continuing, please print `this page`__ as a -memo and hang it onto your desk. - -.. _SQL injection: https://en.wikipedia.org/wiki/SQL_injection -.. __: https://xkcd.com/327/ - -Psycopg can `automatically convert Python objects to SQL values`__: using this -feature your code will be more robust and reliable. We must stress this point: - -.. __: python-types-adaptation_ - -.. warning:: - - - Don't merge manually values to a query: hackers from a foreign country - will break into your computer and steal not only your disks, but also - your cds, leaving you only with the three most embarrassing records you - ever bought. On tape. - - - If you use the ``%`` operator to merge values to a query, con artists - will seduce your cat, who will run away taking your credit card - and your sunglasses with them. - - - If you use ``+`` to merge a textual value to a string, bad guys in - balaclava will find their way to your fridge, drink all your beer, and - leave your toilet sit up and your toilet paper in the wrong orientation. - - - You don't want to merge manually values to a query: :ref:`use the - provided methods ` instead. - -The correct way to pass variables in a SQL command is using the second -argument of the `Cursor.execute()` method:: - - >>> SQL = "INSERT INTO authors (name) VALUES (%s)" # Note: no quotes - >>> data = ("O'Reilly", ) - >>> cur.execute(SQL, data) # Note: no % operator - - -.. index:: - single: Adaptation - pair: Objects; Adaptation - single: Data types; Adaptation - -.. _python-types-adaptation: - -Adaptation of Python values to SQL types ----------------------------------------- - -Many standard Python types are adapted into SQL and returned as Python -objects when a query is executed. - -The following table shows the default mapping between Python and PostgreSQL -types: - -TODO: complete table - -.. only:: html - - .. table:: - :class: data-types - - +--------------------+-------------------------+--------------------------+ - | Python | PostgreSQL | See also | - +====================+=========================+==========================+ - | `!bool` | :sql:`bool` | :ref:`adapt-bool` | - +--------------------+-------------------------+--------------------------+ - | `!float` | | :sql:`real` | :ref:`adapt-numbers` | - | | | :sql:`double` | | - +--------------------+-------------------------+ | - | | `!int` | | :sql:`smallint` | | - | | | | :sql:`integer` | | - | | | :sql:`bigint` | | - +--------------------+-------------------------+ | - | `~decimal.Decimal` | :sql:`numeric` | | - +--------------------+-------------------------+--------------------------+ - | | `!str` | | :sql:`varchar` | :ref:`adapt-string` | - | | | | :sql:`text` | | - +--------------------+-------------------------+--------------------------+ - | | `bytes` | :sql:`bytea` | :ref:`adapt-binary` | - +--------------------+-------------------------+--------------------------+ - | `!date` | :sql:`date` | :ref:`adapt-date` | - +--------------------+-------------------------+ | - | `!time` | | :sql:`time` | | - | | | :sql:`timetz` | | - +--------------------+-------------------------+ | - | `!datetime` | | :sql:`timestamp` | | - | | | :sql:`timestamptz` | | - +--------------------+-------------------------+ | - | `!timedelta` | :sql:`interval` | | - +--------------------+-------------------------+--------------------------+ - | `!list` | :sql:`ARRAY` | :ref:`adapt-list` | - +--------------------+-------------------------+--------------------------+ - | | `!tuple` | Composite types |:ref:`adapt-composite` | - | | `!namedtuple` | | | - +--------------------+-------------------------+--------------------------+ - | `!dict` | :sql:`hstore` | :ref:`adapt-hstore` | - +--------------------+-------------------------+--------------------------+ - | Psycopg's `!Range` | :sql:`range` | :ref:`adapt-range` | - +--------------------+-------------------------+--------------------------+ - | Anything\ |tm| | :sql:`json` | :ref:`adapt-json` | - +--------------------+-------------------------+--------------------------+ - | `~uuid.UUID` | :sql:`uuid` | :ref:`adapt-uuid` | - +--------------------+-------------------------+--------------------------+ - | `ipaddress` | | :sql:`inet` | :ref:`adapt-network` | - | objects | | :sql:`cidr` | | - +--------------------+-------------------------+--------------------------+ - -.. |tm| unicode:: U+2122 - - - -.. index:: - pair: Binary; Parameters - -.. _binary-data: - -Binary parameters and results ------------------------------ - -TODO - - -.. index:: Transactions management -.. index:: InFailedSqlTransaction -.. index:: idle in transaction - -.. _transactions: - -Transaction management -====================== - -`!psycopg3` has a behaviour that may result surprising compared to -:program:`psql`: by default, any database operation will start a new -transaction. As a consequence, changes made by any cursor of the connection -will not be visible until `Connection.commit()` is called, and will be -discarded by `Connection.rollback()`. The following operation on the same -connection will start a new transaction. - -If a database operation fails, the server will refuse further commands, until -a `~rollback()` is called. - -.. hint:: - - If a database operation fails with an error message such as - *InFailedSqlTransaction: current transaction is aborted, commands ignored - until end of transaction block*, it means that **a previous operation - failed** and the database session is in a state of error. You need to call - `!rollback()` if you want to keep on using the same connection. - -The manual commit requirement can be suspended using `~Connection.autocommit`, -either as connection attribute or as `~psycopg3.Connection.connect()` -parameter. This may be required to run operations that need to run outside a -transaction, such as :sql:`CREATE DATABASE`, :sql:`VACUUM`, :sql:`CALL` on -`stored procedures`__ using transaction control. - -.. __: https://www.postgresql.org/docs/current/xproc.html - -.. warning:: - - By default even a simple :sql:`SELECT` will start a transaction: in - long-running programs, if no further action is taken, the session will - remain *idle in transaction*, an undesirable condition for several - reasons (locks are held by the session, tables bloat...). For long lived - scripts, either make sure to terminate a transaction as soon as possible or - use an `~Connection.autocommit` connection. - - -.. _transaction-block: - -Transaction blocks ------------------- - -A more transparent way to make sure that transactions are finalised at the -right time is to use ``with`` `Connection.transaction()` to create a -transaction block. When the block is entered a transaction is started; when -leaving the block the transaction is committed, or it is rolled back if an -exception is raised inside the block. - -For instance, an hypothetical but extremely secure bank may have the following -code to avoid that no accident between the following two lines leaves the -accounts unbalanced: - -.. code:: python - - with conn.transaction(): - move_money(conn, account1, -100) - move_money(conn, account2, +100) - - # The transaction is now committed - -But because the bank is, like, *extremely secure*, they also verify that no -account goes negative: - -.. code:: python - - def move_money(conn, account, amount): - new_balance = add_to_balance(conn, account, amount) - if new_balance < 0: - raise ValueError("account balance cannot go negative") - -In case this function raises an exception, be it the `!ValueError` in the -example or any other exception expected or not, the transaction will be rolled -back, and the exception will propagate out of the `with` block, further down -the call stack. - -Transaction blocks can also be nested (internal transaction blocks are -implemented using SAVEPOINT__): an exception raised inside an inner block -has a chance of being handled and not completely fail outer operations. The -following is an example where a series of operations interact with the -database: operations are allowed to fail, plus we also want to store the -number of operations successfully processed. - -.. __: https://www.postgresql.org/docs/current/sql-savepoint.html - -.. code:: python - - with conn.transaction() as tx1: - num_ok = 0 - for operation in operations: - try: - with conn.transaction() as tx2: - unreliable_operation(conn, operation) - except Exception: - logger.exception(f"{operation} failed") - else: - num_ok += 1 - - save_number_of_successes(conn, num_ok) - -If `!unreliable_operation()` causes an error, including an operation causing a -database error, all its changes will be reverted. The exception bubbles up -outside the block: in the example it is intercepted by the ``try`` so that the -loop can complete. The outermost block is unaffected (unless other errors -happen there). - -You can also write code to explicitly roll back any currently active -transaction block, by raising the `Rollback` exception. The exception "jumps" -to the end of a transaction block, rolling back its transaction but allowing -the program execution to continue from there. By default the exception rolls -back the innermost transaction block, but any current block can be specified -as the target. In the following example, an hypothetical `!CancelCommand` -may stop the processing and cancel any operation previously performed, -but not entirely committed yet. - -.. code:: python - - from psycopg3 import Rollback - - with conn.transaction() as outer_tx: - for command in commands(): - with conn.transaction() as inner_tx: - if isinstance(command, CancelCommand): - raise Rollback(outer_tx) - process_command(command) - - # If `Rollback` is raised, it would propagate only up to this block, - # and the program would continue from here with no exception. - - -.. index:: - pair: COPY; SQL command - -.. _copy: - -Using COPY TO and COPY FROM -=========================== - -`psycopg3` allows to operate with `PostgreSQL COPY protocol`__. :sql:`COPY` is -one of the most efficient ways to load data into the database (and to modify -it, with some SQL creativity). - -.. __: https://www.postgresql.org/docs/current/sql-copy.html - -Using `!psycopg3` you can do three things: - -- loading data into the database row-by-row, from a stream of Python objects; -- loading data into the database block-by-block, with data already formatted in - a way suitable for :sql:`COPY FROM`; -- reading data from the database block-by-block, with data emitted by a - :sql:`COPY TO` statement. - -The missing quadrant, copying data from the database row-by-row, is not -covered by COPY because that's pretty much normal querying, and :sql:`COPY TO` -doesn't offer enough metadata to decode the data to Python objects. - -The first option is the most powerful, because it allows to load data into the -database from any Python iterable (a list of tuple, or any iterable of -sequences): the Python values are adapted as they would be in normal querying. -To perform such operation use a :sql:`COPY [table] FROM STDIN` with -`Cursor.copy()` and use `~Copy.write_row()` on the resulting object in a -``with`` block. On exiting the block the operation will be concluded: - -.. code:: python - - with cursor.copy("COPY table_name (col1, col2) FROM STDIN") as copy: - for row in source: - copy.write_row(row) - -If an exception is raised inside the block, the operation is interrupted and -the records inserted so far discarded. - -If data is already formatted in a way suitable for copy (for instance because -it is coming from a file resulting from a previous `COPY TO` operation) it can -be loaded using `Copy.write()` instead. - -In order to read data in :sql:`COPY` format you can use a :sql:`COPY TO -STDOUT` statement and iterate over the resulting `Copy` object, which will -produce `!bytes`: - -.. code:: python - - with open("data.out", "wb") as f: - with cursor.copy("COPY table_name TO STDOUT") as copy: - for data in copy: - f.write(data) - -Asynchronous operations are supported using the same patterns on an -`AsyncConnection`. For instance, if `!f` is an object supporting an -asynchronous `!read()` method returning :sql:`COPY` data, a fully-async copy -operation could be: - -.. code:: python - - async with cursor.copy("COPY data FROM STDIN") as copy: - while data := await f.read() - await copy.write(data) - -Binary data can be produced and consumed using :sql:`FORMAT BINARY` in the -:sql:`COPY` command: see :ref:`binary-data` for details and limitations. - - -.. index:: asyncio - -Async operations -================ - -psycopg3 `~Connection` and `~Cursor` have counterparts `~AsyncConnection` and -`~AsyncCursor` supporting an `asyncio` interface. - -The design of the asynchronous objects is pretty much the same of the sync -ones: in order to use them you will only have to scatter the ``await`` keyword -here and there. - -.. code:: python - - async with await psycopg3.AsyncConnection.connect( - "dbname=test user=postgres") as aconn: - async with await aconn.cursor() as acur: - await acur.execute( - "INSERT INTO test (num, data) VALUES (%s, %s)", - (100, "abc'def")) - await acur.execute("SELECT * FROM test") - await acur.fetchone() - # will return (1, 100, "abc'def") - async for record in acur: - print(record) - - - -.. index:: - pair: Asynchronous; Notifications - pair: LISTEN; SQL command - pair: NOTIFY; SQL command - -.. _async-notify: - -Asynchronous notifications --------------------------- - -Psycopg allows asynchronous interaction with other database sessions using the -facilities offered by PostgreSQL commands |LISTEN|_ and |NOTIFY|_. Please -refer to the PostgreSQL documentation for examples about how to use this form -of communication. - -.. |LISTEN| replace:: :sql:`LISTEN` -.. _LISTEN: https://www.postgresql.org/docs/current/static/sql-listen.html -.. |NOTIFY| replace:: :sql:`NOTIFY` -.. _NOTIFY: https://www.postgresql.org/docs/current/static/sql-notify.html - -Because of the way sessions interact with notifications (see |NOTIFY|_ -documentation), you should keep the connection in `~Connection.autocommit` -mode if you wish to receive or send notifications in a timely manner. - -Notifications are received as instances of `Notify`. If you are reserving a -connection only to receive notifications, the simplest way is to consume the -`Connection.notifies` generator. The generator can be stopped using -``close()``. The following example will print notifications and stop when one -containing the ``stop`` message is received. - -.. code:: python - - import psycopg3 - conn = psycopg3.connect("", autocommit=True) - conn.cursor().execute("LISTEN mychan") - gen = conn.notifies() - for notify in gen: - print(notify) - if notify.payload == "stop": - gen.close() - print("there, I stopped") - -If you run some :sql:`NOTIFY` in a :program:`psql` session: - -.. code:: psql - - =# notify mychan, 'hello'; - NOTIFY - =# notify mychan, 'hey'; - NOTIFY - =# notify mychan, 'stop'; - NOTIFY - -You may get output from the Python process such as:: - - Notify(channel='mychan', payload='hello', pid=961823) - Notify(channel='mychan', payload='hey', pid=961823) - Notify(channel='mychan', payload='stop', pid=961823) - there, I stopped - -Alternatively, you can use `~Connection.add_notify_handler()` to register a -callback function, which will be invoked whenever a notification is received, -during the normal query processing; you will be then able to use the -connection normally. Please note that in this case notifications will not be -received immediately, but only during a connection operation, such as a query. - -.. code:: python - - conn.add_notify_handler(lambda n: print(f"got this: {n}")) +.. seealso:: - # meanwhile in psql... - # =# notify mychan, 'hey'; - # NOTIFY + A few important topics you will have to deal with are: - print(conn.cursor().execute("select 1").fetchone()) - # got this: Notify(channel='mychan', payload='hey', pid=961823) - # (1,) + - :ref:`query-parameters`. + - :ref:`types-adaptation`. + - :ref:`transactions`. diff --git a/psycopg3/psycopg3/sql.py b/psycopg3/psycopg3/sql.py index 249830ae8..b0dbcb5d4 100644 --- a/psycopg3/psycopg3/sql.py +++ b/psycopg3/psycopg3/sql.py @@ -293,7 +293,7 @@ class Identifier(Composable): fields. PostgreSQL identifiers follow `different rules`__ than SQL string literals for escaping (e.g. they use double quotes instead of single). - .. __: https://www.postgresql.org/docs/current/static/sql-syntax-lexical.html# \ + .. __: https://www.postgresql.org/docs/current/sql-syntax-lexical.html# \ SQL-SYNTAX-IDENTIFIERS Example:: @@ -357,7 +357,7 @@ class Literal(Composable): include a literal value in the query you can use this object. The string returned by `!as_string()` follows the normal :ref:`adaptation - rules ` for Python objects. + rules ` for Python objects. Example::