Doc: improve PREPARE documentation, cross-referencing to plan_cache_mode.

The behavior described in the PREPARE man page applies only for the
default plan_cache_mode setting, so explain that properly.  Rewrite
some of the text while I'm here.  Per suggestion from Bruce.

Discussion: https://postgr.es/m/20190930155505.GA21095@momjian.us
This commit is contained in:
Tom Lane 2019-09-30 14:31:12 -04:00
parent 7e0fb165dd
commit ce734aaec1
2 changed files with 50 additions and 43 deletions

View File

@ -5318,23 +5318,21 @@ SELECT * FROM parent WHERE key = 2400;
<listitem> <listitem>
<para> <para>
Prepared statements (either explicitly prepared or implicitly Prepared statements (either explicitly prepared or implicitly
generated, for example in PL/pgSQL) can be executed using custom or generated, for example by PL/pgSQL) can be executed using custom or
generic plans. A custom plan is replanned for a new parameter value, generic plans. Custom plans are made afresh for each execution
a generic plan is reused for repeated executions of the prepared using its specific set of parameter values, while generic plans do
statement. The choice between them is normally made automatically. not rely on the parameter values and can be re-used across
This setting overrides the default behavior and forces either a custom executions. Thus, use of a generic plan saves planning time, but if
or a generic plan. This can be used to work around performance the ideal plan depends strongly on the parameter values then a
problems in specific cases. Note, however, that the plan cache generic plan may be inefficient. The choice between these options
behavior is subject to change, so this setting, like all settings that is normally made automatically, but it can be overridden
force the planner's hand, should be reevaluated regularly. with <varname>plan_cache_mode</varname>.
</para> The allowed values are <literal>auto</literal> (the default),
<para>
The allowed values are <literal>auto</literal>,
<literal>force_custom_plan</literal> and <literal>force_custom_plan</literal> and
<literal>force_generic_plan</literal>. The default value is <literal>force_generic_plan</literal>.
<literal>auto</literal>. The setting is applied when a cached plan is This setting is considered when a cached plan is to be executed,
to be executed, not when it is prepared. not when it is prepared.
For more information see <xref linkend="sql-prepare"/>.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>

View File

@ -127,40 +127,49 @@ PREPARE <replaceable class="parameter">name</replaceable> [ ( <replaceable class
<title>Notes</title> <title>Notes</title>
<para> <para>
Prepared statements can use generic plans rather than re-planning with A prepared statement can be executed with either a <firstterm>generic
each set of supplied <command>EXECUTE</command> values. This occurs plan</firstterm> or a <firstterm>custom plan</firstterm>. A generic
immediately for prepared statements with no parameters; otherwise plan is the same across all executions, while a custom plan is generated
it occurs only after five or more executions produce plans whose for a specific execution using the parameter values given in that call.
estimated cost average (including planning overhead) is more expensive Use of a generic plan avoids planning overhead, but in some situations
than the generic plan cost estimate. Once a generic plan is chosen, a custom plan will be much more efficient to execute because the planner
it is used for the remaining lifetime of the prepared statement. can make use of knowledge of the parameter values. (Of course, if the
Using <command>EXECUTE</command> values which are rare in columns with prepared statement has no parameters, then this is moot and a generic
many duplicates can generate custom plans that are so much cheaper plan is always used.)
than the generic plan, even after adding planning overhead, that the
generic plan might never be used.
</para> </para>
<para> <para>
A generic plan assumes that each value supplied to By default (that is, when <xref linkend="guc-plan-cache_mode"/> is set
<command>EXECUTE</command> is one of the column's distinct values to <literal>auto</literal>), the server will automatically choose
and that column values are uniformly distributed. For example, whether to use a generic or custom plan for a prepared statement that
if statistics record three distinct column values, a generic plan has parameters. The current rule for this is that the first five
assumes a column equality comparison will match 33% of processed rows. executions are done with custom plans and the average estimated cost of
Column statistics also allow generic plans to accurately compute the those plans is calculated. Then a generic plan is created and its
selectivity of unique columns. Comparisons on non-uniformly-distributed estimated cost is compared to the average custom-plan cost. Subsequent
columns and specification of non-existent values affects the average executions use the generic plan if its cost is not so much higher than
plan cost, and hence if and when a generic plan is chosen. the average custom-plan cost as to make repeated replanning seem
preferable.
</para>
<para>
This heuristic can be overridden, forcing the server to use either
generic or custom plans, by setting <varname>plan_cache_mode</varname>
to <literal>force_generic_plan</literal>
or <literal>force_custom_plan</literal> respectively.
This setting is primarily useful if the generic plan's cost estimate
is badly off for some reason, allowing it to be chosen even though
its actual cost is much more than that of a custom plan.
</para> </para>
<para> <para>
To examine the query plan <productname>PostgreSQL</productname> is using To examine the query plan <productname>PostgreSQL</productname> is using
for a prepared statement, use <xref linkend="sql-explain"/>, e.g. for a prepared statement, use <xref linkend="sql-explain"/>, for example
<command>EXPLAIN EXECUTE</command>. <programlisting>
EXPLAIN EXECUTE <replaceable>stmt_name</replaceable>(<replaceable>parameter_values</replaceable>);
</programlisting>
If a generic plan is in use, it will contain parameter symbols If a generic plan is in use, it will contain parameter symbols
<literal>$<replaceable>n</replaceable></literal>, while a custom plan will have the <literal>$<replaceable>n</replaceable></literal>, while a custom plan
supplied parameter values substituted into it. will have the supplied parameter values substituted into it.
The row estimates in the generic plan reflect the selectivity
computed for the parameters.
</para> </para>
<para> <para>
@ -221,7 +230,7 @@ PREPARE usrrptplan (int) AS
EXECUTE usrrptplan(1, current_date); EXECUTE usrrptplan(1, current_date);
</programlisting> </programlisting>
Note that the data type of the second parameter is not specified, In this example, the data type of the second parameter is not specified,
so it is inferred from the context in which <literal>$2</literal> is used. so it is inferred from the context in which <literal>$2</literal> is used.
</para> </para>
</refsect1> </refsect1>