1PREPARE(7) PostgreSQL 9.2.24 Documentation PREPARE(7)
2
3
4
6 PREPARE - prepare a statement for execution
7
9 PREPARE name [ ( data_type [, ...] ) ] AS statement
10
12 PREPARE creates a prepared statement. A prepared statement is a
13 server-side object that can be used to optimize performance. When the
14 PREPARE statement is executed, the specified statement is parsed,
15 analyzed, and rewritten. When an EXECUTE command is subsequently
16 issued, the prepared statement is planned and executed. This division
17 of labor avoids repetitive parse analysis work, while allowing the
18 execution plan to depend on the specific parameter values supplied.
19
20 Prepared statements can take parameters: values that are substituted
21 into the statement when it is executed. When creating the prepared
22 statement, refer to parameters by position, using $1, $2, etc. A
23 corresponding list of parameter data types can optionally be specified.
24 When a parameter's data type is not specified or is declared as
25 unknown, the type is inferred from the context in which the parameter
26 is used (if possible). When executing the statement, specify the actual
27 values for these parameters in the EXECUTE statement. Refer to
28 EXECUTE(7) for more information about that.
29
30 Prepared statements only last for the duration of the current database
31 session. When the session ends, the prepared statement is forgotten, so
32 it must be recreated before being used again. This also means that a
33 single prepared statement cannot be used by multiple simultaneous
34 database clients; however, each client can create their own prepared
35 statement to use. Prepared statements can be manually cleaned up using
36 the DEALLOCATE(7) command.
37
38 Prepared statements have the largest performance advantage when a
39 single session is being used to execute a large number of similar
40 statements. The performance difference will be particularly significant
41 if the statements are complex to plan or rewrite, for example, if the
42 query involves a join of many tables or requires the application of
43 several rules. If the statement is relatively simple to plan and
44 rewrite but relatively expensive to execute, the performance advantage
45 of prepared statements will be less noticeable.
46
48 name
49 An arbitrary name given to this particular prepared statement. It
50 must be unique within a single session and is subsequently used to
51 execute or deallocate a previously prepared statement.
52
53 data_type
54 The data type of a parameter to the prepared statement. If the data
55 type of a particular parameter is unspecified or is specified as
56 unknown, it will be inferred from the context in which the
57 parameter is used. To refer to the parameters in the prepared
58 statement itself, use $1, $2, etc.
59
60 statement
61 Any SELECT, INSERT, UPDATE, DELETE, or VALUES statement.
62
64 If a prepared statement is executed enough times, the server may
65 eventually decide to save and re-use a generic plan rather than
66 re-planning each time. This will occur immediately if the prepared
67 statement has no parameters; otherwise it occurs only if the generic
68 plan appears to be not much more expensive than a plan that depends on
69 specific parameter values. Typically, a generic plan will be selected
70 only if the query's performance is estimated to be fairly insensitive
71 to the specific parameter values supplied.
72
73 To examine the query plan PostgreSQL is using for a prepared statement,
74 use EXPLAIN(7). If a generic plan is in use, it will contain parameter
75 symbols $n, while a custom plan will have the current actual parameter
76 values substituted into it.
77
78 For more information on query planning and the statistics collected by
79 PostgreSQL for that purpose, see the ANALYZE(7) documentation.
80
81 You can see all prepared statements available in the session by
82 querying the pg_prepared_statements system view.
83
85 Create a prepared statement for an INSERT statement, and then execute
86 it:
87
88 PREPARE fooplan (int, text, bool, numeric) AS
89 INSERT INTO foo VALUES($1, $2, $3, $4);
90 EXECUTE fooplan(1, 'Hunter Valley', 't', 200.00);
91
92 Create a prepared statement for a SELECT statement, and then execute
93 it:
94
95 PREPARE usrrptplan (int) AS
96 SELECT * FROM users u, logs l WHERE u.usrid=$1 AND u.usrid=l.usrid
97 AND l.date = $2;
98 EXECUTE usrrptplan(1, current_date);
99
100 Note that the data type of the second parameter is not specified, so it
101 is inferred from the context in which $2 is used.
102
104 The SQL standard includes a PREPARE statement, but it is only for use
105 in embedded SQL. This version of the PREPARE statement also uses a
106 somewhat different syntax.
107
109 DEALLOCATE(7), EXECUTE(7)
110
111
112
113PostgreSQL 9.2.24 2017-11-06 PREPARE(7)