| From: | Laurenz Albe <laurenz(dot)albe(at)cybertec(dot)at> |
|---|---|
| To: | Yuri Kutsko <ykutsko(at)gmail(dot)com>, pgsql-general(at)lists(dot)postgresql(dot)org |
| Subject: | Re: EXPLAIN(GENERIC_PLAN) failing for some queries |
| Date: | 2026-01-08 08:27:16 |
| Message-ID: | d4a9c31ffcfdd68f1b66bdb66fd7b7680af99f96.camel@cybertec.at |
| Views: | Whole Thread | Raw Message | Download mbox | Resend email |
| Thread: | |
| Lists: | pgsql-general |
On Wed, 2026-01-07 at 14:57 -0800, Yuri Kutsko wrote:
> I want to identify every query in my company’s database that potentially uses full table scans.
> To do this, I wrote a simple PL/pgSQL function that generates an execution plan for each query
> from pg_stat_statements and then searches the plan for the 'Seq Scan' pattern.
> Most queries contain parameters, so I use EXPLAIN (GENERIC_PLAN). This works for approximately
> 80% of queries, but it fails in the following scenarios:
>
> 1. Planner cannot infer parameter types without explicit casts
> The following fails: EXPLAIN (GENERIC_PLAN) SELECT * FROM tbl WHERE id = $1 + $2;
> The following works: EXPLAIN (GENERIC_PLAN) SELECT * FROM tbl WHERE id = $1::integer + $2::integer;
>
> 2. Parameter is used in EXTRACT
> The following fails: EXPLAIN (GENERIC_PLAN) SELECT * FROM tbl WHERE EXTRACT($1 FROM date_col) = 1;
> The following works: EXPLAIN (GENERIC_PLAN) SELECT * FROM tbl WHERE date_part($1, date_col) = 1;
>
> 3. Parameter is used in type 'string' notation
> The following fails: EXPLAIN (GENERIC_PLAN) SELECT int $1;
> The following works: EXPLAIN (GENERIC_PLAN) SELECT $1::int;
>
> I modified my procedure to account for these scenarios, but I am not sure whether there are other
> issues with EXPLAIN (GENERIC_PLAN) that I am not aware of.
> Problem #1 is mentioned in the EXPLAIN documentation
> (https://www.postgresql.org/docs/18/sql-explain.html) at the bottom of the page, but the other cases are not.
> My questions are:
> Are all of the issues described above expected behavior for EXPLAIN (GENERIC_PLAN)?
Yes.
Note that your cases #2 and #3 are illegal SQL, since you cannot use a parameter in these places,
only string literals. I'd say that your problem is that you are using strings from pg_stat_statements,
which ignores the value of constants. Replacing literals with placeholders can result in incorrect
SQL statements.
> Are there other known scenarios where EXPLAIN (GENERIC_PLAN) will fail?
It is expected to fail for all statements with syntax errors...
> Should the EXPLAIN documentation be updated to list scenarios in which EXPLAIN (GENERIC_PLAN) can fail?
I don't think that #2 and #3 deserve documentation, and I'd say it doesn't need to be documented
that EXPLAIN will fail for syntactically incorrect SQL.
Yours,
Laurenz Albe
| From | Date | Subject | |
|---|---|---|---|
| Next Message | Rihad | 2026-01-08 12:34:40 | Collation again here |
| Previous Message | Tom Lane | 2026-01-08 04:03:02 | Re: Fwd: pg18 bug? SELECT query doesn't work |