Skip to content

Commit 3c05284

Browse files
committed
Invent GENERIC_PLAN option for EXPLAIN.
This provides a very simple way to see the generic plan for a parameterized query. Without this, it's necessary to define a prepared statement and temporarily change plan_cache_mode, which is a bit tedious. One thing that's a bit of a hack perhaps is that we disable execution-time partition pruning when the GENERIC_PLAN option is given. That's because the pruning code may attempt to fetch the value of one of the parameters, which would fail. Laurenz Albe, reviewed by Julien Rouhaud, Christoph Berg, Michel Pelletier, Jim Jones, and myself Discussion: https://postgr.es/m/0a29b954b10b57f0d135fe12aa0909bd41883eb0.camel@cybertec.at
1 parent 5b140dc commit 3c05284

File tree

10 files changed

+197
-20
lines changed

10 files changed

+197
-20
lines changed

doc/src/sgml/ref/explain.sgml

Lines changed: 62 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -40,6 +40,7 @@ EXPLAIN [ ANALYZE ] [ VERBOSE ] <replaceable class="parameter">statement</replac
4040
VERBOSE [ <replaceable class="parameter">boolean</replaceable> ]
4141
COSTS [ <replaceable class="parameter">boolean</replaceable> ]
4242
SETTINGS [ <replaceable class="parameter">boolean</replaceable> ]
43+
GENERIC_PLAN [ <replaceable class="parameter">boolean</replaceable> ]
4344
BUFFERS [ <replaceable class="parameter">boolean</replaceable> ]
4445
WAL [ <replaceable class="parameter">boolean</replaceable> ]
4546
TIMING [ <replaceable class="parameter">boolean</replaceable> ]
@@ -168,6 +169,22 @@ ROLLBACK;
168169
</listitem>
169170
</varlistentry>
170171

172+
<varlistentry>
173+
<term><literal>GENERIC_PLAN</literal></term>
174+
<listitem>
175+
<para>
176+
Allow the statement to contain parameter placeholders like
177+
<literal>$1</literal>, and generate a generic plan that does not
178+
depend on the values of those parameters.
179+
See <link linkend="sql-prepare"><command>PREPARE</command></link>
180+
for details about generic plans and the types of statement that
181+
support parameters.
182+
This parameter cannot be used together with <literal>ANALYZE</literal>.
183+
It defaults to <literal>FALSE</literal>.
184+
</para>
185+
</listitem>
186+
</varlistentry>
187+
171188
<varlistentry>
172189
<term><literal>BUFFERS</literal></term>
173190
<listitem>
@@ -191,7 +208,7 @@ ROLLBACK;
191208
query processing.
192209
The number of blocks shown for an
193210
upper-level node includes those used by all its child nodes. In text
194-
format, only non-zero values are printed. It defaults to
211+
format, only non-zero values are printed. This parameter defaults to
195212
<literal>FALSE</literal>.
196213
</para>
197214
</listitem>
@@ -445,14 +462,15 @@ PREPARE query(int, int) AS SELECT sum(bar) FROM test
445462
EXPLAIN ANALYZE EXECUTE query(100, 200);
446463

447464
QUERY PLAN
448-
-------------------------------------------------------------------&zwsp;-----------------------------------------------------
449-
HashAggregate (cost=9.54..9.54 rows=1 width=8) (actual time=0.156..0.161 rows=11 loops=1)
465+
-------------------------------------------------------------------&zwsp;------------------------------------------------------
466+
HashAggregate (cost=10.77..10.87 rows=10 width=12) (actual time=0.043..0.044 rows=10 loops=1)
450467
Group Key: foo
451-
-&gt; Index Scan using test_pkey on test (cost=0.29..9.29 rows=50 width=8) (actual time=0.039..0.091 rows=99 loops=1)
452-
Index Cond: ((id &gt; $1) AND (id &lt; $2))
453-
Planning time: 0.197 ms
454-
Execution time: 0.225 ms
455-
(6 rows)
468+
Batches: 1 Memory Usage: 24kB
469+
-&gt; Index Scan using test_pkey on test (cost=0.29..10.27 rows=99 width=8) (actual time=0.009..0.025 rows=99 loops=1)
470+
Index Cond: ((id &gt; 100) AND (id &lt; 200))
471+
Planning Time: 0.244 ms
472+
Execution Time: 0.073 ms
473+
(7 rows)
456474
</programlisting>
457475
</para>
458476

@@ -467,6 +485,42 @@ EXPLAIN ANALYZE EXECUTE query(100, 200);
467485
<command>ANALYZE</command>, even if the actual distribution of data
468486
in the table has not changed.
469487
</para>
488+
489+
<para>
490+
Notice that the previous example showed a <quote>custom</quote> plan
491+
for the specific parameter values given in <command>EXECUTE</command>.
492+
We might also wish to see the generic plan for a parameterized
493+
query, which can be done with <literal>GENERIC_PLAN</literal>:
494+
495+
<programlisting>
496+
EXPLAIN (GENERIC_PLAN)
497+
SELECT sum(bar) FROM test
498+
WHERE id &gt; $1 AND id &lt; $2
499+
GROUP BY foo;
500+
501+
QUERY PLAN
502+
-------------------------------------------------------------------&zwsp;------------
503+
HashAggregate (cost=26.79..26.89 rows=10 width=12)
504+
Group Key: foo
505+
-&gt; Index Scan using test_pkey on test (cost=0.29..24.29 rows=500 width=8)
506+
Index Cond: ((id &gt; $1) AND (id &lt; $2))
507+
(4 rows)
508+
</programlisting>
509+
510+
In this case the parser correctly inferred that <literal>$1</literal>
511+
and <literal>$2</literal> should have the same data type
512+
as <literal>id</literal>, so the lack of parameter type information
513+
from <command>PREPARE</command> was not a problem. In other cases
514+
it might be necessary to explicitly specify types for the parameter
515+
symbols, which can be done by casting them, for example:
516+
517+
<programlisting>
518+
EXPLAIN (GENERIC_PLAN)
519+
SELECT sum(bar) FROM test
520+
WHERE id &gt; $1::integer AND id &lt; $2::integer
521+
GROUP BY foo;
522+
</programlisting>
523+
</para>
470524
</refsect1>
471525

472526
<refsect1>

src/backend/commands/explain.c

Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -190,6 +190,8 @@ ExplainQuery(ParseState *pstate, ExplainStmt *stmt,
190190
es->wal = defGetBoolean(opt);
191191
else if (strcmp(opt->defname, "settings") == 0)
192192
es->settings = defGetBoolean(opt);
193+
else if (strcmp(opt->defname, "generic_plan") == 0)
194+
es->generic = defGetBoolean(opt);
193195
else if (strcmp(opt->defname, "timing") == 0)
194196
{
195197
timing_set = true;
@@ -227,6 +229,7 @@ ExplainQuery(ParseState *pstate, ExplainStmt *stmt,
227229
parser_errposition(pstate, opt->location)));
228230
}
229231

232+
/* check that WAL is used with EXPLAIN ANALYZE */
230233
if (es->wal && !es->analyze)
231234
ereport(ERROR,
232235
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
@@ -241,6 +244,12 @@ ExplainQuery(ParseState *pstate, ExplainStmt *stmt,
241244
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
242245
errmsg("EXPLAIN option TIMING requires ANALYZE")));
243246

247+
/* check that GENERIC_PLAN is not used with EXPLAIN ANALYZE */
248+
if (es->generic && es->analyze)
249+
ereport(ERROR,
250+
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
251+
errmsg("EXPLAIN options ANALYZE and GENERIC_PLAN cannot be used together")));
252+
244253
/* if the summary was not set explicitly, set default value */
245254
es->summary = (summary_set) ? es->summary : es->analyze;
246255

@@ -572,6 +581,8 @@ ExplainOnePlan(PlannedStmt *plannedstmt, IntoClause *into, ExplainState *es,
572581
eflags = 0; /* default run-to-completion flags */
573582
else
574583
eflags = EXEC_FLAG_EXPLAIN_ONLY;
584+
if (es->generic)
585+
eflags |= EXEC_FLAG_EXPLAIN_GENERIC;
575586
if (into)
576587
eflags |= GetIntoRelEFlags(into);
577588

src/backend/executor/execMain.c

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -911,7 +911,7 @@ InitPlan(QueryDesc *queryDesc, int eflags)
911911
* prepared to handle REWIND efficiently; otherwise there is no need.
912912
*/
913913
sp_eflags = eflags
914-
& (EXEC_FLAG_EXPLAIN_ONLY | EXEC_FLAG_WITH_NO_DATA);
914+
& ~(EXEC_FLAG_REWIND | EXEC_FLAG_BACKWARD | EXEC_FLAG_MARK);
915915
if (bms_is_member(i, plannedstmt->rewindPlanIDs))
916916
sp_eflags |= EXEC_FLAG_REWIND;
917917

src/backend/executor/execPartition.c

Lines changed: 7 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -2044,10 +2044,13 @@ CreatePartitionPruneState(PlanState *planstate, PartitionPruneInfo *pruneinfo)
20442044
pprune->present_parts = bms_copy(pinfo->present_parts);
20452045

20462046
/*
2047-
* Initialize pruning contexts as needed.
2047+
* Initialize pruning contexts as needed. Note that we must skip
2048+
* execution-time partition pruning in EXPLAIN (GENERIC_PLAN),
2049+
* since parameter values may be missing.
20482050
*/
20492051
pprune->initial_pruning_steps = pinfo->initial_pruning_steps;
2050-
if (pinfo->initial_pruning_steps)
2052+
if (pinfo->initial_pruning_steps &&
2053+
!(econtext->ecxt_estate->es_top_eflags & EXEC_FLAG_EXPLAIN_GENERIC))
20512054
{
20522055
InitPartitionPruneContext(&pprune->initial_context,
20532056
pinfo->initial_pruning_steps,
@@ -2057,7 +2060,8 @@ CreatePartitionPruneState(PlanState *planstate, PartitionPruneInfo *pruneinfo)
20572060
prunestate->do_initial_prune = true;
20582061
}
20592062
pprune->exec_pruning_steps = pinfo->exec_pruning_steps;
2060-
if (pinfo->exec_pruning_steps)
2063+
if (pinfo->exec_pruning_steps &&
2064+
!(econtext->ecxt_estate->es_top_eflags & EXEC_FLAG_EXPLAIN_GENERIC))
20612065
{
20622066
InitPartitionPruneContext(&pprune->exec_context,
20632067
pinfo->exec_pruning_steps,

src/backend/parser/analyze.c

Lines changed: 29 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -27,6 +27,7 @@
2727
#include "access/sysattr.h"
2828
#include "catalog/pg_proc.h"
2929
#include "catalog/pg_type.h"
30+
#include "commands/defrem.h"
3031
#include "miscadmin.h"
3132
#include "nodes/makefuncs.h"
3233
#include "nodes/nodeFuncs.h"
@@ -2906,10 +2907,38 @@ static Query *
29062907
transformExplainStmt(ParseState *pstate, ExplainStmt *stmt)
29072908
{
29082909
Query *result;
2910+
bool generic_plan = false;
2911+
Oid *paramTypes = NULL;
2912+
int numParams = 0;
2913+
2914+
/*
2915+
* If we have no external source of parameter definitions, and the
2916+
* GENERIC_PLAN option is specified, then accept variable parameter
2917+
* definitions (similarly to PREPARE, for example).
2918+
*/
2919+
if (pstate->p_paramref_hook == NULL)
2920+
{
2921+
ListCell *lc;
2922+
2923+
foreach(lc, stmt->options)
2924+
{
2925+
DefElem *opt = (DefElem *) lfirst(lc);
2926+
2927+
if (strcmp(opt->defname, "generic_plan") == 0)
2928+
generic_plan = defGetBoolean(opt);
2929+
/* don't "break", as we want the last value */
2930+
}
2931+
if (generic_plan)
2932+
setup_parse_variable_parameters(pstate, &paramTypes, &numParams);
2933+
}
29092934

29102935
/* transform contained query, allowing SELECT INTO */
29112936
stmt->query = (Node *) transformOptionalSelectInto(pstate, stmt->query);
29122937

2938+
/* make sure all is well with parameter types */
2939+
if (generic_plan)
2940+
check_variable_parameters(pstate, (Query *) stmt->query);
2941+
29132942
/* represent the command as a utility Query */
29142943
result = makeNode(Query);
29152944
result->commandType = CMD_UTILITY;

src/bin/psql/tab-complete.c

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -3752,9 +3752,9 @@ psql_completion(const char *text, int start, int end)
37523752
* one word, so the above test is correct.
37533753
*/
37543754
if (ends_with(prev_wd, '(') || ends_with(prev_wd, ','))
3755-
COMPLETE_WITH("ANALYZE", "VERBOSE", "COSTS", "SETTINGS",
3755+
COMPLETE_WITH("ANALYZE", "VERBOSE", "COSTS", "SETTINGS", "GENERIC_PLAN",
37563756
"BUFFERS", "WAL", "TIMING", "SUMMARY", "FORMAT");
3757-
else if (TailMatches("ANALYZE|VERBOSE|COSTS|SETTINGS|BUFFERS|WAL|TIMING|SUMMARY"))
3757+
else if (TailMatches("ANALYZE|VERBOSE|COSTS|SETTINGS|GENERIC_PLAN|BUFFERS|WAL|TIMING|SUMMARY"))
37583758
COMPLETE_WITH("ON", "OFF");
37593759
else if (TailMatches("FORMAT"))
37603760
COMPLETE_WITH("TEXT", "XML", "JSON", "YAML");

src/include/commands/explain.h

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -46,6 +46,7 @@ typedef struct ExplainState
4646
bool timing; /* print detailed node timing */
4747
bool summary; /* print total planning and execution timing */
4848
bool settings; /* print modified settings */
49+
bool generic; /* generate a generic plan */
4950
ExplainFormat format; /* output format */
5051
/* state for output formatting --- not reset for each new plan tree */
5152
int indent; /* current indentation level */

src/include/executor/executor.h

Lines changed: 16 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -36,6 +36,11 @@
3636
* of startup should occur. However, error checks (such as permission checks)
3737
* should be performed.
3838
*
39+
* EXPLAIN_GENERIC can only be used together with EXPLAIN_ONLY. It indicates
40+
* that a generic plan is being shown using EXPLAIN (GENERIC_PLAN), which
41+
* means that missing parameter values must be tolerated. Currently, the only
42+
* effect is to suppress execution-time partition pruning.
43+
*
3944
* REWIND indicates that the plan node should try to efficiently support
4045
* rescans without parameter changes. (Nodes must support ExecReScan calls
4146
* in any case, but if this flag was not given, they are at liberty to do it
@@ -52,13 +57,18 @@
5257
* AfterTriggerBeginQuery/AfterTriggerEndQuery. This does not necessarily
5358
* mean that the plan can't queue any AFTER triggers; just that the caller
5459
* is responsible for there being a trigger context for them to be queued in.
60+
*
61+
* WITH_NO_DATA indicates that we are performing REFRESH MATERIALIZED VIEW
62+
* ... WITH NO DATA. Currently, the only effect is to suppress errors about
63+
* scanning unpopulated materialized views.
5564
*/
56-
#define EXEC_FLAG_EXPLAIN_ONLY 0x0001 /* EXPLAIN, no ANALYZE */
57-
#define EXEC_FLAG_REWIND 0x0002 /* need efficient rescan */
58-
#define EXEC_FLAG_BACKWARD 0x0004 /* need backward scan */
59-
#define EXEC_FLAG_MARK 0x0008 /* need mark/restore */
60-
#define EXEC_FLAG_SKIP_TRIGGERS 0x0010 /* skip AfterTrigger calls */
61-
#define EXEC_FLAG_WITH_NO_DATA 0x0020 /* rel scannability doesn't matter */
65+
#define EXEC_FLAG_EXPLAIN_ONLY 0x0001 /* EXPLAIN, no ANALYZE */
66+
#define EXEC_FLAG_EXPLAIN_GENERIC 0x0002 /* EXPLAIN (GENERIC_PLAN) */
67+
#define EXEC_FLAG_REWIND 0x0004 /* need efficient rescan */
68+
#define EXEC_FLAG_BACKWARD 0x0008 /* need backward scan */
69+
#define EXEC_FLAG_MARK 0x0010 /* need mark/restore */
70+
#define EXEC_FLAG_SKIP_TRIGGERS 0x0020 /* skip AfterTrigger setup */
71+
#define EXEC_FLAG_WITH_NO_DATA 0x0040 /* REFRESH ... WITH NO DATA */
6272

6373

6474
/* Hook for plugins to get control in ExecutorStart() */

src/test/regress/expected/explain.out

Lines changed: 42 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -308,6 +308,48 @@ select explain_filter_to_json('explain (settings, format json) select * from int
308308
(1 row)
309309

310310
rollback;
311+
-- GENERIC_PLAN option
312+
select explain_filter('explain (generic_plan) select unique1 from tenk1 where thousand = $1');
313+
explain_filter
314+
---------------------------------------------------------------------------------
315+
Bitmap Heap Scan on tenk1 (cost=N.N..N.N rows=N width=N)
316+
Recheck Cond: (thousand = $N)
317+
-> Bitmap Index Scan on tenk1_thous_tenthous (cost=N.N..N.N rows=N width=N)
318+
Index Cond: (thousand = $N)
319+
(4 rows)
320+
321+
-- should fail
322+
select explain_filter('explain (analyze, generic_plan) select unique1 from tenk1 where thousand = $1');
323+
ERROR: EXPLAIN options ANALYZE and GENERIC_PLAN cannot be used together
324+
CONTEXT: PL/pgSQL function explain_filter(text) line 5 at FOR over EXECUTE statement
325+
-- Test EXPLAIN (GENERIC_PLAN) with partition pruning
326+
-- partitions should be pruned at plan time, based on constants,
327+
-- but there should be no pruning based on parameter placeholders
328+
create table gen_part (
329+
key1 integer not null,
330+
key2 integer not null
331+
) partition by list (key1);
332+
create table gen_part_1
333+
partition of gen_part for values in (1)
334+
partition by range (key2);
335+
create table gen_part_1_1
336+
partition of gen_part_1 for values from (1) to (2);
337+
create table gen_part_1_2
338+
partition of gen_part_1 for values from (2) to (3);
339+
create table gen_part_2
340+
partition of gen_part for values in (2);
341+
-- should scan gen_part_1_1 and gen_part_1_2, but not gen_part_2
342+
select explain_filter('explain (generic_plan) select key1, key2 from gen_part where key1 = 1 and key2 = $1');
343+
explain_filter
344+
---------------------------------------------------------------------------
345+
Append (cost=N.N..N.N rows=N width=N)
346+
-> Seq Scan on gen_part_1_1 gen_part_1 (cost=N.N..N.N rows=N width=N)
347+
Filter: ((key1 = N) AND (key2 = $N))
348+
-> Seq Scan on gen_part_1_2 gen_part_2 (cost=N.N..N.N rows=N width=N)
349+
Filter: ((key1 = N) AND (key2 = $N))
350+
(5 rows)
351+
352+
drop table gen_part;
311353
--
312354
-- Test production of per-worker data
313355
--

src/test/regress/sql/explain.sql

Lines changed: 26 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -88,6 +88,32 @@ select true as "OK"
8888
select explain_filter_to_json('explain (settings, format json) select * from int8_tbl i8') #> '{0,Settings,plan_cache_mode}';
8989
rollback;
9090

91+
-- GENERIC_PLAN option
92+
93+
select explain_filter('explain (generic_plan) select unique1 from tenk1 where thousand = $1');
94+
-- should fail
95+
select explain_filter('explain (analyze, generic_plan) select unique1 from tenk1 where thousand = $1');
96+
97+
-- Test EXPLAIN (GENERIC_PLAN) with partition pruning
98+
-- partitions should be pruned at plan time, based on constants,
99+
-- but there should be no pruning based on parameter placeholders
100+
create table gen_part (
101+
key1 integer not null,
102+
key2 integer not null
103+
) partition by list (key1);
104+
create table gen_part_1
105+
partition of gen_part for values in (1)
106+
partition by range (key2);
107+
create table gen_part_1_1
108+
partition of gen_part_1 for values from (1) to (2);
109+
create table gen_part_1_2
110+
partition of gen_part_1 for values from (2) to (3);
111+
create table gen_part_2
112+
partition of gen_part for values in (2);
113+
-- should scan gen_part_1_1 and gen_part_1_2, but not gen_part_2
114+
select explain_filter('explain (generic_plan) select key1, key2 from gen_part where key1 = 1 and key2 = $1');
115+
drop table gen_part;
116+
91117
--
92118
-- Test production of per-worker data
93119
--

0 commit comments

Comments
 (0)