1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>PREPARE</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="sql-notify.html" title="NOTIFY" /><link rel="next" href="sql-prepare-transaction.html" title="PREPARE TRANSACTION" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">PREPARE</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="sql-notify.html" title="NOTIFY">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><th width="60%" align="center">SQL Commands</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="sql-prepare-transaction.html" title="PREPARE TRANSACTION">Next</a></td></tr></table><hr /></div><div class="refentry" id="SQL-PREPARE"><div class="titlepage"></div><a id="id-1.9.3.159.1" class="indexterm"></a><a id="id-1.9.3.159.2" class="indexterm"></a><div class="refnamediv"><h2><span class="refentrytitle">PREPARE</span></h2><p>PREPARE — prepare a statement for execution</p></div><div class="refsynopsisdiv"><h2>Synopsis</h2><pre class="synopsis">
3 PREPARE <em class="replaceable"><code>name</code></em> [ ( <em class="replaceable"><code>data_type</code></em> [, ...] ) ] AS <em class="replaceable"><code>statement</code></em>
4 </pre></div><div class="refsect1" id="id-1.9.3.159.6"><h2>Description</h2><p>
5 <code class="command">PREPARE</code> creates a prepared statement. A prepared
6 statement is a server-side object that can be used to optimize
7 performance. When the <code class="command">PREPARE</code> statement is
8 executed, the specified statement is parsed, analyzed, and rewritten.
9 When an <code class="command">EXECUTE</code> command is subsequently
10 issued, the prepared statement is planned and executed. This division
11 of labor avoids repetitive parse analysis work, while allowing
12 the execution plan to depend on the specific parameter values supplied.
14 Prepared statements can take parameters: values that are
15 substituted into the statement when it is executed. When creating
16 the prepared statement, refer to parameters by position, using
17 <code class="literal">$1</code>, <code class="literal">$2</code>, etc. A corresponding list of
18 parameter data types can optionally be specified. When a
19 parameter's data type is not specified or is declared as
20 <code class="literal">unknown</code>, the type is inferred from the context
21 in which the parameter is first referenced (if possible). When executing the
22 statement, specify the actual values for these parameters in the
23 <code class="command">EXECUTE</code> statement. Refer to <a class="xref" href="sql-execute.html" title="EXECUTE"><span class="refentrytitle">EXECUTE</span></a> for more
24 information about that.
26 Prepared statements only last for the duration of the current
27 database session. When the session ends, the prepared statement is
28 forgotten, so it must be recreated before being used again. This
29 also means that a single prepared statement cannot be used by
30 multiple simultaneous database clients; however, each client can create
31 their own prepared statement to use. Prepared statements can be
32 manually cleaned up using the <a class="link" href="sql-deallocate.html" title="DEALLOCATE"><code class="command">DEALLOCATE</code></a> command.
34 Prepared statements potentially have the largest performance advantage
35 when a single session is being used to execute a large number of similar
36 statements. The performance difference will be particularly
37 significant if the statements are complex to plan or rewrite, e.g.,
38 if the query involves a join of many tables or requires
39 the application of several rules. If the statement is relatively simple
40 to plan and rewrite but relatively expensive to execute, the
41 performance advantage of prepared statements will be less noticeable.
42 </p></div><div class="refsect1" id="id-1.9.3.159.7"><h2>Parameters</h2><div class="variablelist"><dl class="variablelist"><dt><span class="term"><em class="replaceable"><code>name</code></em></span></dt><dd><p>
43 An arbitrary name given to this particular prepared
44 statement. It must be unique within a single session and is
45 subsequently used to execute or deallocate a previously prepared
47 </p></dd><dt><span class="term"><em class="replaceable"><code>data_type</code></em></span></dt><dd><p>
48 The data type of a parameter to the prepared statement. If the
49 data type of a particular parameter is unspecified or is
50 specified as <code class="literal">unknown</code>, it will be inferred
51 from the context in which the parameter is first referenced. To refer to the
52 parameters in the prepared statement itself, use
53 <code class="literal">$1</code>, <code class="literal">$2</code>, etc.
54 </p></dd><dt><span class="term"><em class="replaceable"><code>statement</code></em></span></dt><dd><p>
55 Any <code class="command">SELECT</code>, <code class="command">INSERT</code>, <code class="command">UPDATE</code>,
56 <code class="command">DELETE</code>, <code class="command">MERGE</code>, or <code class="command">VALUES</code>
58 </p></dd></dl></div></div><div class="refsect1" id="SQL-PREPARE-NOTES"><h2>Notes</h2><p>
59 A prepared statement can be executed with either a <em class="firstterm">generic
60 plan</em> or a <em class="firstterm">custom plan</em>. A generic
61 plan is the same across all executions, while a custom plan is generated
62 for a specific execution using the parameter values given in that call.
63 Use of a generic plan avoids planning overhead, but in some situations
64 a custom plan will be much more efficient to execute because the planner
65 can make use of knowledge of the parameter values. (Of course, if the
66 prepared statement has no parameters, then this is moot and a generic
69 By default (that is, when <a class="xref" href="runtime-config-query.html#GUC-PLAN-CACHE-MODE">plan_cache_mode</a> is set
70 to <code class="literal">auto</code>), the server will automatically choose
71 whether to use a generic or custom plan for a prepared statement that
72 has parameters. The current rule for this is that the first five
73 executions are done with custom plans and the average estimated cost of
74 those plans is calculated. Then a generic plan is created and its
75 estimated cost is compared to the average custom-plan cost. Subsequent
76 executions use the generic plan if its cost is not so much higher than
77 the average custom-plan cost as to make repeated replanning seem
80 This heuristic can be overridden, forcing the server to use either
81 generic or custom plans, by setting <code class="varname">plan_cache_mode</code>
82 to <code class="literal">force_generic_plan</code>
83 or <code class="literal">force_custom_plan</code> respectively.
84 This setting is primarily useful if the generic plan's cost estimate
85 is badly off for some reason, allowing it to be chosen even though
86 its actual cost is much more than that of a custom plan.
88 To examine the query plan <span class="productname">PostgreSQL</span> is using
89 for a prepared statement, use <a class="link" href="sql-explain.html" title="EXPLAIN"><code class="command">EXPLAIN</code></a>, for example
90 </p><pre class="programlisting">
91 EXPLAIN EXECUTE <em class="replaceable"><code>name</code></em>(<em class="replaceable"><code>parameter_values</code></em>);
93 If a generic plan is in use, it will contain parameter symbols
94 <code class="literal">$<em class="replaceable"><code>n</code></em></code>, while a custom plan
95 will have the supplied parameter values substituted into it.
97 For more information on query planning and the statistics collected
98 by <span class="productname">PostgreSQL</span> for that purpose, see
99 the <a class="xref" href="sql-analyze.html" title="ANALYZE"><span class="refentrytitle">ANALYZE</span></a>
102 Although the main point of a prepared statement is to avoid repeated parse
103 analysis and planning of the statement, <span class="productname">PostgreSQL</span> will
104 force re-analysis and re-planning of the statement before using it
105 whenever database objects used in the statement have undergone
106 definitional (DDL) changes or their planner statistics have
107 been updated since the previous use of the prepared
108 statement. Also, if the value of <a class="xref" href="runtime-config-client.html#GUC-SEARCH-PATH">search_path</a> changes
109 from one use to the next, the statement will be re-parsed using the new
110 <code class="varname">search_path</code>. (This latter behavior is new as of
111 <span class="productname">PostgreSQL</span> 9.3.) These rules make use of a
112 prepared statement semantically almost equivalent to re-submitting the
113 same query text over and over, but with a performance benefit if no object
114 definitions are changed, especially if the best plan remains the same
115 across uses. An example of a case where the semantic equivalence is not
116 perfect is that if the statement refers to a table by an unqualified name,
117 and then a new table of the same name is created in a schema appearing
118 earlier in the <code class="varname">search_path</code>, no automatic re-parse will occur
119 since no object used in the statement changed. However, if some other
120 change forces a re-parse, the new table will be referenced in subsequent
123 You can see all prepared statements available in the session by querying the
124 <a class="link" href="view-pg-prepared-statements.html" title="53.16. pg_prepared_statements"><code class="structname">pg_prepared_statements</code></a>
126 </p></div><div class="refsect1" id="SQL-PREPARE-EXAMPLES"><h2>Examples</h2><p>
127 Create a prepared statement for an <code class="command">INSERT</code>
128 statement, and then execute it:
129 </p><pre class="programlisting">
130 PREPARE fooplan (int, text, bool, numeric) AS
131 INSERT INTO foo VALUES($1, $2, $3, $4);
132 EXECUTE fooplan(1, 'Hunter Valley', 't', 200.00);
135 Create a prepared statement for a <code class="command">SELECT</code>
136 statement, and then execute it:
137 </p><pre class="programlisting">
138 PREPARE usrrptplan (int) AS
139 SELECT * FROM users u, logs l WHERE u.usrid=$1 AND u.usrid=l.usrid
141 EXECUTE usrrptplan(1, current_date);
144 In this example, the data type of the second parameter is not specified,
145 so it is inferred from the context in which <code class="literal">$2</code> is used.
146 </p></div><div class="refsect1" id="id-1.9.3.159.10"><h2>Compatibility</h2><p>
147 The SQL standard includes a <code class="command">PREPARE</code> statement,
148 but it is only for use in embedded SQL. This version of the
149 <code class="command">PREPARE</code> statement also uses a somewhat different
151 </p></div><div class="refsect1" id="id-1.9.3.159.11"><h2>See Also</h2><span class="simplelist"><a class="xref" href="sql-deallocate.html" title="DEALLOCATE"><span class="refentrytitle">DEALLOCATE</span></a>, <a class="xref" href="sql-execute.html" title="EXECUTE"><span class="refentrytitle">EXECUTE</span></a></span></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="sql-notify.html" title="NOTIFY">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="sql-prepare-transaction.html" title="PREPARE TRANSACTION">Next</a></td></tr><tr><td width="40%" align="left" valign="top">NOTIFY </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> PREPARE TRANSACTION</td></tr></table></div></body></html>