aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/prepare.sgml
blob: d0abc49b5ce302b0e6d79bcd8a66863748b103ce (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
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/prepare.sgml,v 1.16 2005/10/15 01:47:12 neilc Exp $
PostgreSQL documentation
-->

<refentry id="SQL-PREPARE">
 <refmeta>
  <refentrytitle id="sql-prepare-title">PREPARE</refentrytitle>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

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

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

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

 <refsynopsisdiv>
<synopsis>
PREPARE <replaceable class="PARAMETER">plan_name</replaceable> [ (<replaceable class="PARAMETER">datatype</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, rewritten, and
   planned. When an <command>EXECUTE</command> command is subsequently
   issued, the prepared statement need only be executed. Thus, the
   parsing, rewriting, and planning stages are only performed once,
   instead of every time the statement is executed.
  </para>

  <para>
   Prepared statements can take parameters: values that are
   substituted into the statement when it is executed. To include
   parameters in a prepared statement, supply a list of data types in
   the <command>PREPARE</command> statement, and, in the statement to
   be prepared itself, refer to the parameters by position using
   <literal>$1</literal>, <literal>$2</literal>, etc. When executing
   the statement, specify the actual values for these parameters in
   the <command>EXECUTE</command> statement.  Refer to <xref
   linkend="sql-execute" endterm="sql-execute-title"> 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.  The prepared statement can be
   manually cleaned up using the <xref linkend="sql-deallocate"
   endterm="sql-deallocate-title"> command.
  </para>

  <para>
   Prepared statements 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, for
   example, 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">plan_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">datatype</replaceable></term>
    <listitem>
     <para>
      The data type of a parameter to the prepared statement.  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>INSERT</>, <command>UPDATE</>,
      or <command>DELETE</> statement.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1>
  <title>Notes</title>

  <para>
   In some situations, the query plan produced for a prepared
   statement will be inferior to the query plan that would have been
   chosen if the statement had been submitted and executed
   normally. This is because when the statement is planned and the
   planner attempts to determine the optimal query plan, the actual
   values of any parameters specified in the statement are
   unavailable. <productname>PostgreSQL</productname> collects
   statistics on the distribution of data in the table, and can use
   constant values in a statement to make guesses about the likely
   result of executing the statement. Since this data is unavailable
   when planning prepared statements with parameters, the chosen plan
   may be suboptimal. To examine the query plan
   <productname>PostgreSQL</productname> has chosen for a prepared
   statement, use <xref linkend="sql-explain"
   endterm="sql-explain-title">.
  </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" endterm="sql-analyze-title">
   documentation.
  </para>
 </refsect1>

 <refsect1 id="sql-prepare-examples">
  <title id="sql-prepare-examples-title">Examples</title>
  <para>
   Create a prepared query 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 query for a <command>SELECT</command> statement,
   and then execute it:
<programlisting>
PREPARE usrrptplan (int, date) 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>
  </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" endterm="sql-deallocate-title"></member>
   <member><xref linkend="sql-execute" endterm="sql-execute-title"></member>
  </simplelist>
 </refsect1>
</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->