On Fri, 6 Dec 2024 at 02:27, Daniel Johnson <djohnson@progman.us> wrote:
>
> Good day! I've run into a quirk executing an SQL statement and am not
> sure if it's a fundamental issue with my query or a bug in psycopg3.
It's a mix of an issue with your query, postgres being too forgiving
in parsing the interval, and psycopg 3 behaving very differently from
psycopg 2.
Your query assumes a literal replacement of the placeholder in the
query, which was true in psycopg 2, but in psycopg 3 uses real
placeholders. However it doesn't parse the query to check if a
placeholder is in a string or not (arguably it shouldn't touch the
ones in the strings, but no, we don't parse queries). So the %s as you
have seen becomes a $4, but postgres will not replace that parameter
with a value, because it will surely parse the query and will not
touch the string.
Arguably, Postgres should complain about a malformed interval literal,
but this behaviour was probably designed in times in which the
principle "be conservative in what you do, be liberal in what you
accept from others" was still considered a good idea and fixing it
would kill too many dinosaurs.
Adrian has already provided a few workarounds for the problem you
report - thank you very much!. The one I prefer is however the
following, because it does without string operations: it makes use of
the possibility to multiply an interval by a scalar:
>>> cur.execute("select now(), now() + %s * '1 second'::interval",
(10,)).fetchone()
(datetime.datetime(2024, 12, 6, 2, 33, 32, 117134,
tzinfo=zoneinfo.ZoneInfo(key='Europe/London')),
datetime.datetime(2024, 12, 6, 2, 33, 42, 117134,
tzinfo=zoneinfo.ZoneInfo(key='Europe/London')))
cheers
-- Daniele