summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/man7/PREPARE.7
blob: b16a8f01b2406d7582ab73fa0546b2cdb2aed6e7 (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
'\" t
.\"     Title: PREPARE
.\"    Author: The PostgreSQL Global Development Group
.\" Generator: DocBook XSL Stylesheets vsnapshot <http://docbook.sf.net/>
.\"      Date: 2023
.\"    Manual: PostgreSQL 15.4 Documentation
.\"    Source: PostgreSQL 15.4
.\"  Language: English
.\"
.TH "PREPARE" "7" "2023" "PostgreSQL 15.4" "PostgreSQL 15.4 Documentation"
.\" -----------------------------------------------------------------
.\" * Define some portability stuff
.\" -----------------------------------------------------------------
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.\" http://bugs.debian.org/507673
.\" http://lists.gnu.org/archive/html/groff/2009-02/msg00013.html
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.ie \n(.g .ds Aq \(aq
.el       .ds Aq '
.\" -----------------------------------------------------------------
.\" * set default formatting
.\" -----------------------------------------------------------------
.\" disable hyphenation
.nh
.\" disable justification (adjust text to left margin only)
.ad l
.\" -----------------------------------------------------------------
.\" * MAIN CONTENT STARTS HERE *
.\" -----------------------------------------------------------------
.SH "NAME"
PREPARE \- prepare a statement for execution
.SH "SYNOPSIS"
.sp
.nf
PREPARE \fIname\fR [ ( \fIdata_type\fR [, \&.\&.\&.] ) ] AS \fIstatement\fR
.fi
.SH "DESCRIPTION"
.PP
\fBPREPARE\fR
creates a prepared statement\&. A prepared statement is a server\-side object that can be used to optimize performance\&. When the
\fBPREPARE\fR
statement is executed, the specified statement is parsed, analyzed, and rewritten\&. When an
\fBEXECUTE\fR
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\&.
.PP
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
$1,
$2, etc\&. A corresponding list of parameter data types can optionally be specified\&. When a parameter\*(Aqs data type is not specified or is declared as
unknown, 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
\fBEXECUTE\fR
statement\&. Refer to
\fBEXECUTE\fR(7)
for more information about that\&.
.PP
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
\fBDEALLOCATE\fR
command\&.
.PP
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\&.
.SH "PARAMETERS"
.PP
\fIname\fR
.RS 4
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\&.
.RE
.PP
\fIdata_type\fR
.RS 4
The data type of a parameter to the prepared statement\&. If the data type of a particular parameter is unspecified or is specified as
unknown, 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
$1,
$2, etc\&.
.RE
.PP
\fIstatement\fR
.RS 4
Any
\fBSELECT\fR,
\fBINSERT\fR,
\fBUPDATE\fR,
\fBDELETE\fR,
\fBMERGE\fR, or
\fBVALUES\fR
statement\&.
.RE
.SH "NOTES"
.PP
A prepared statement can be executed with either a
generic plan
or a
custom plan\&. 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\&.)
.PP
By default (that is, when
plan_cache_mode
is set to
auto), 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\&.
.PP
This heuristic can be overridden, forcing the server to use either generic or custom plans, by setting
\fIplan_cache_mode\fR
to
force_generic_plan
or
force_custom_plan
respectively\&. This setting is primarily useful if the generic plan\*(Aqs 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\&.
.PP
To examine the query plan
PostgreSQL
is using for a prepared statement, use
\fBEXPLAIN\fR, for example
.sp
.if n \{\
.RS 4
.\}
.nf
EXPLAIN EXECUTE \fIname\fR(\fIparameter_values\fR);
.fi
.if n \{\
.RE
.\}
.sp
If a generic plan is in use, it will contain parameter symbols
$\fIn\fR, while a custom plan will have the supplied parameter values substituted into it\&.
.PP
For more information on query planning and the statistics collected by
PostgreSQL
for that purpose, see the
\fBANALYZE\fR(7)
documentation\&.
.PP
Although the main point of a prepared statement is to avoid repeated parse analysis and planning of the statement,
PostgreSQL
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
search_path
changes from one use to the next, the statement will be re\-parsed using the new
\fIsearch_path\fR\&. (This latter behavior is new as of
PostgreSQL
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
\fIsearch_path\fR, 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\&.
.PP
You can see all prepared statements available in the session by querying the
pg_prepared_statements
system view\&.
.SH "EXAMPLES"
.PP
Create a prepared statement for an
\fBINSERT\fR
statement, and then execute it:
.sp
.if n \{\
.RS 4
.\}
.nf
PREPARE fooplan (int, text, bool, numeric) AS
    INSERT INTO foo VALUES($1, $2, $3, $4);
EXECUTE fooplan(1, \*(AqHunter Valley\*(Aq, \*(Aqt\*(Aq, 200\&.00);
.fi
.if n \{\
.RE
.\}
.PP
Create a prepared statement for a
\fBSELECT\fR
statement, and then execute it:
.sp
.if n \{\
.RS 4
.\}
.nf
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);
.fi
.if n \{\
.RE
.\}
.sp
In this example, the data type of the second parameter is not specified, so it is inferred from the context in which
$2
is used\&.
.SH "COMPATIBILITY"
.PP
The SQL standard includes a
\fBPREPARE\fR
statement, but it is only for use in embedded SQL\&. This version of the
\fBPREPARE\fR
statement also uses a somewhat different syntax\&.
.SH "SEE ALSO"
\fBDEALLOCATE\fR(7), \fBEXECUTE\fR(7)