Re: Query with boolean parameter

From: Daniele Varrazzo <daniele(dot)varrazzo(at)gmail(dot)com>
To: Paolo De Stefani <paolo(at)paolodestefani(dot)it>
Cc: Christophe Pettus <xof(at)thebuild(dot)com>, Psycopg <psycopg(at)postgresql(dot)org>
Subject: Re: Query with boolean parameter
Date: 2022-03-19 13:43:19
Message-ID: CA+mi_8aSJgi_iCdvCwpYnDpoWRbRYfgsS1bHH+97tzSJcEcKNQ@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: psycopg

> Il 19/03/2022 01:00 Christophe Pettus ha scritto:> >> On Mar 18, 2022, at 16:56, Paolo De Stefani <paolo(at)paolodestefani(dot)it>
> >> wrote:
> >> Is there any reason why the second query results in a syntax error?
> >
> > There's not IS operator in PostgreSQL (or in SQL). IS NULL, IS NOT
> > NULL, IS TRUE, and IS FALSE are in effect unary postfix operators, so
> > you can't construct them that way via parameter substitution.

That's unexpected. Thank you for the insight, Christophe.

On Sat, 19 Mar 2022 at 13:11, Paolo De Stefani <paolo(at)paolodestefani(dot)it> wrote:

> The problem is (for me) that with psycopg2 this works:
> cur.execute('SELECT * FROM system.app_user WHERE can_edit_views IS
> TRUE')
> cur.execute('SELECT * FROM system.app_user WHERE can_edit_views IS %s',
> (True,))
> cur.execute('SELECT * FROM system.app_user WHERE can_edit_views IS %s',
> (None,))
>
> Switching to psycopg 3 i have to consider many more differences than i
> expected

Maybe you can play around with IS NOT DISTINCT FROM?

https://www.postgresql.org/docs/current/functions-comparison.html

In [1]: import psycopg
In [2]: cnn = psycopg.connect(autocommit=True)

In [5]: cnn.execute("create table dist (id int primary key, cond bool)")
In [7]: cnn.cursor().executemany("insert into dist values (%s,
%s)", [(1, True), (2, False), (3, None)])

In [9]: cnn.execute("select * from dist where cond is not distinct
from %s", [True]).fetchone()
Out[9]: (1, True)

In [10]: cnn.execute("select * from dist where cond is not
distinct from %s", [False]).fetchone()
Out[10]: (2, False)

In [11]: cnn.execute("select * from dist where cond is not
distinct from %s", [None]).fetchone()
Out[11]: (3, None)

-- Daniele

In response to

Browse psycopg by date

  From Date Subject
Next Message Christophe Pettus 2022-03-19 16:35:08 Re: Query with boolean parameter
Previous Message Paolo De Stefani 2022-03-19 12:10:54 Re: Query with boolean parameter