summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/ref/prepare.sgml
blob: 8ee9439f611141c6578c485940e11ff6a5e8cfeb (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
<!--
doc/src/sgml/ref/prepare.sgml
PostgreSQL documentation
-->

<refentry id="sql-prepare">
 <indexterm zone="sql-prepare">
  <primary>PREPARE</primary>
 </indexterm>

 <indexterm zone="sql-prepare">
  <primary>prepared statements</primary>
  <secondary>creating</secondary>
 </indexterm>

 <refmeta>
  <refentrytitle>PREPARE</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>PREPARE</refname>
  <refpurpose>prepare a statement for execution</refpurpose>
 </refnamediv>

 <refsynopsisdiv>
<synopsis>
PREPARE <replaceable class="parameter">name</replaceable> [ ( <replaceable class="parameter">data_type</replaceable> [, ...] ) ] AS <replaceable class="parameter">statement</replaceable>
</synopsis>
 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

  <para>
   <command>PREPARE</command> creates a prepared statement. A prepared
   statement is a server-side object that can be used to optimize
   performance. When the <command>PREPARE</command> statement is
   executed, the specified statement is parsed, analyzed, and rewritten.
   When an <command>EXECUTE</command> command is subsequently
   issued, the prepared statement is planned and executed.  This division
   of labor avoids repetitive parse analysis work, while allowing
   the execution plan to depend on the specific parameter values supplied.
  </para>

  <para>
   Prepared statements can take parameters: values that are
   substituted into the statement when it is executed. When creating
   the prepared statement, refer to parameters by position, using
   <literal>$1</literal>, <literal>$2</literal>, etc. A corresponding list of
   parameter data types can optionally be specified. When a
   parameter's data type is not specified or is declared as
   <literal>unknown</literal>, the type is inferred from the context
   in which the parameter is first referenced (if possible). When executing the
   statement, specify the actual values for these parameters in the
   <command>EXECUTE</command> statement.  Refer to <xref
   linkend="sql-execute"/> for more
   information about that.
  </para>

  <para>
   Prepared statements only last for the duration of the current
   database session. When the session ends, the prepared statement is
   forgotten, so it must be recreated before being used again. This
   also means that a single  prepared statement cannot be used by
   multiple simultaneous database clients; however, each client can create
   their own prepared statement to use.  Prepared statements can be
   manually cleaned up using the <link linkend="sql-deallocate"><command>DEALLOCATE</command></link> command.
  </para>

  <para>
   Prepared statements potentially have the largest performance advantage
   when a single session is being used to execute a large number of similar
   statements. The performance difference will be particularly
   significant if the statements are complex to plan or rewrite, e.g.,
   if the query involves a join of many tables or requires
   the application of several rules. If the statement is relatively simple
   to plan and rewrite but relatively expensive to execute, the
   performance advantage of prepared statements will be less noticeable.
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <variablelist>
   <varlistentry>
    <term><replaceable class="parameter">name</replaceable></term>
    <listitem>
     <para>
      An arbitrary name given to this particular prepared
      statement. It must be unique within a single session and is
      subsequently used to execute or deallocate a previously prepared
      statement.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">data_type</replaceable></term>
    <listitem>
     <para>
      The data type of a parameter to the prepared statement.  If the
      data type of a particular parameter is unspecified or is
      specified as <literal>unknown</literal>, it will be inferred
      from the context in which the parameter is first referenced. To refer to the
      parameters in the prepared statement itself, use
      <literal>$1</literal>, <literal>$2</literal>, etc.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">statement</replaceable></term>
    <listitem>
     <para>
      Any <command>SELECT</command>, <command>INSERT</command>, <command>UPDATE</command>,
      <command>DELETE</command>, <command>MERGE</command>, or <command>VALUES</command>
      statement.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1 id="sql-prepare-notes">
  <title>Notes</title>

  <para>
   A prepared statement can be executed with either a <firstterm>generic
   plan</firstterm> or a <firstterm>custom plan</firstterm>.  A generic
   plan is the same across all executions, while a custom plan is generated
   for a specific execution using the parameter values given in that call.
   Use of a generic plan avoids planning overhead, but in some situations
   a custom plan will be much more efficient to execute because the planner
   can make use of knowledge of the parameter values.  (Of course, if the
   prepared statement has no parameters, then this is moot and a generic
   plan is always used.)
  </para>

  <para>
   By default (that is, when <xref linkend="guc-plan-cache-mode"/> is set
   to <literal>auto</literal>), the server will automatically choose
   whether to use a generic or custom plan for a prepared statement that
   has parameters.  The current rule for this is that the first five
   executions are done with custom plans and the average estimated cost of
   those plans is calculated.  Then a generic plan is created and its
   estimated cost is compared to the average custom-plan cost.  Subsequent
   executions use the generic plan if its cost is not so much higher than
   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>
   To examine the query plan <productname>PostgreSQL</productname> is using
   for a prepared statement, use <link linkend="sql-explain"><command>EXPLAIN</command></link>, for example
<programlisting>
EXPLAIN EXECUTE <replaceable>name</replaceable>(<replaceable>parameter_values</replaceable>);
</programlisting>
   If a generic plan is in use, it will contain parameter symbols
   <literal>$<replaceable>n</replaceable></literal>, while a custom plan
   will have the supplied parameter values substituted into it.
  </para>

  <para>
   For more information on query planning and the statistics collected
   by <productname>PostgreSQL</productname> for that purpose, see
   the <xref linkend="sql-analyze"/>
   documentation.
  </para>

  <para>
   Although the main point of a prepared statement is to avoid repeated parse
   analysis and planning of the statement, <productname>PostgreSQL</productname> will
   force re-analysis and re-planning of the statement before using it
   whenever database objects used in the statement have undergone
   definitional (DDL) changes or their planner statistics have
   been updated since the previous use of the prepared
   statement.  Also, if the value of <xref linkend="guc-search-path"/> changes
   from one use to the next, the statement will be re-parsed using the new
   <varname>search_path</varname>.  (This latter behavior is new as of
   <productname>PostgreSQL</productname> 9.3.)  These rules make use of a
   prepared statement semantically almost equivalent to re-submitting the
   same query text over and over, but with a performance benefit if no object
   definitions are changed, especially if the best plan remains the same
   across uses.  An example of a case where the semantic equivalence is not
   perfect is that if the statement refers to a table by an unqualified name,
   and then a new table of the same name is created in a schema appearing
   earlier in the <varname>search_path</varname>, no automatic re-parse will occur
   since no object used in the statement changed.  However, if some other
   change forces a re-parse, the new table will be referenced in subsequent
   uses.
  </para>

  <para>
   You can see all prepared statements available in the session by querying the
   <link linkend="view-pg-prepared-statements"><structname>pg_prepared_statements</structname></link>
   system view.
  </para>
 </refsect1>

 <refsect1 id="sql-prepare-examples" xreflabel="Examples">
  <title>Examples</title>
  <para>
   Create a prepared statement for an <command>INSERT</command>
   statement, and then execute it:
<programlisting>
PREPARE fooplan (int, text, bool, numeric) AS
    INSERT INTO foo VALUES($1, $2, $3, $4);
EXECUTE fooplan(1, 'Hunter Valley', 't', 200.00);
</programlisting>
  </para>

  <para>
   Create a prepared statement for a <command>SELECT</command>
   statement, and then execute it:
<programlisting>
PREPARE usrrptplan (int) AS
    SELECT * FROM users u, logs l WHERE u.usrid=$1 AND u.usrid=l.usrid
    AND l.date = $2;
EXECUTE usrrptplan(1, current_date);
</programlisting>

   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.
  </para>
 </refsect1>
 <refsect1>
  <title>Compatibility</title>

  <para>
   The SQL standard includes a <command>PREPARE</command> statement,
   but it is only for use in embedded SQL. This version of the
   <command>PREPARE</command> statement also uses a somewhat different
   syntax.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-deallocate"/></member>
   <member><xref linkend="sql-execute"/></member>
  </simplelist>
 </refsect1>
</refentry>