From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Maciek Sakrejda <m(dot)sakrejda(at)gmail(dot)com> |
Cc: | pgsql-hackers <pgsql-hackers(at)postgresql(dot)org> |
Subject: | Re: Differences between = ANY and IN? |
Date: | 2023-10-03 05:15:31 |
Message-ID: | 2222856.1696310131@sss.pgh.pa.us |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-hackers |
Maciek Sakrejda <m(dot)sakrejda(at)gmail(dot)com> writes:
> My colleague's patch changes SQL generated from Ruby expressions like
> `where(id: [1, 2])` . This is currently translated to roughly `WHERE
> id IN (1, 2)` and would be changed to `id = ANY('{1,2}')`.
> As far as we know, the expressions are equivalent, but we wanted to
> double-check: are there any edge cases to consider here (other than
> the pg_stat_statements behavior, of course)?
You would find it profitable to read transformAExprIn() in parse_expr.c.
The most important points are in this comment:
* We try to generate a ScalarArrayOpExpr from IN/NOT IN, but this is only
* possible if there is a suitable array type available. If not, we fall
* back to a boolean condition tree with multiple copies of the lefthand
* expression. Also, any IN-list items that contain Vars are handled as
* separate boolean conditions, because that gives the planner more scope
* for optimization on such clauses.
If all the values in the IN form were being sent to the backend as
constants of the same datatype, I think you're okay to consider it
as exactly equivalent to =ANY. It would likely be a good idea to
provide an explicit cast `id = ANY('{1,2}'::int[])` rather than just
hoping an unadorned literal will be taken as the type you want
(see transformAExprOpAny and thence make_scalar_array_op).
regards, tom lane
From | Date | Subject | |
---|---|---|---|
Next Message | Maciek Sakrejda | 2023-10-03 06:24:06 | Re: pg_stat_statements and "IN" conditions |
Previous Message | David Rowley | 2023-10-03 05:02:10 | Re: Making aggregate deserialization (and WAL receive) functions slightly faster |