1DECLARE(7) PostgreSQL 9.2.24 Documentation DECLARE(7)
2
3
4
6 DECLARE - define a cursor
7
9 DECLARE name [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ]
10 CURSOR [ { WITH | WITHOUT } HOLD ] FOR query
11
13 DECLARE allows a user to create cursors, which can be used to retrieve
14 a small number of rows at a time out of a larger query. After the
15 cursor is created, rows are fetched from it using FETCH(7).
16
17 Note
18 This page describes usage of cursors at the SQL command level. If
19 you are trying to use cursors inside a PL/pgSQL function, the rules
20 are different — see Section 39.7, “Cursors”, in the documentation.
21
23 name
24 The name of the cursor to be created.
25
26 BINARY
27 Causes the cursor to return data in binary rather than in text
28 format.
29
30 INSENSITIVE
31 Indicates that data retrieved from the cursor should be unaffected
32 by updates to the table(s) underlying the cursor that occur after
33 the cursor is created. In PostgreSQL, this is the default behavior;
34 so this key word has no effect and is only accepted for
35 compatibility with the SQL standard.
36
37 SCROLL, NO SCROLL
38 SCROLL specifies that the cursor can be used to retrieve rows in a
39 nonsequential fashion (e.g., backward). Depending upon the
40 complexity of the query's execution plan, specifying SCROLL might
41 impose a performance penalty on the query's execution time. NO
42 SCROLL specifies that the cursor cannot be used to retrieve rows in
43 a nonsequential fashion. The default is to allow scrolling in some
44 cases; this is not the same as specifying SCROLL. See NOTES for
45 details.
46
47 WITH HOLD, WITHOUT HOLD
48 WITH HOLD specifies that the cursor can continue to be used after
49 the transaction that created it successfully commits. WITHOUT HOLD
50 specifies that the cursor cannot be used outside of the transaction
51 that created it. If neither WITHOUT HOLD nor WITH HOLD is
52 specified, WITHOUT HOLD is the default.
53
54 query
55 A SELECT(7) or VALUES(7) command which will provide the rows to be
56 returned by the cursor.
57
58 The key words BINARY, INSENSITIVE, and SCROLL can appear in any order.
59
61 Normal cursors return data in text format, the same as a SELECT would
62 produce. The BINARY option specifies that the cursor should return data
63 in binary format. This reduces conversion effort for both the server
64 and client, at the cost of more programmer effort to deal with
65 platform-dependent binary data formats. As an example, if a query
66 returns a value of one from an integer column, you would get a string
67 of 1 with a default cursor, whereas with a binary cursor you would get
68 a 4-byte field containing the internal representation of the value (in
69 big-endian byte order).
70
71 Binary cursors should be used carefully. Many applications, including
72 psql, are not prepared to handle binary cursors and expect data to come
73 back in the text format.
74
75 Note
76 When the client application uses the “extended query” protocol to
77 issue a FETCH command, the Bind protocol message specifies whether
78 data is to be retrieved in text or binary format. This choice
79 overrides the way that the cursor is defined. The concept of a
80 binary cursor as such is thus obsolete when using extended query
81 protocol — any cursor can be treated as either text or binary.
82
83 Unless WITH HOLD is specified, the cursor created by this command can
84 only be used within the current transaction. Thus, DECLARE without WITH
85 HOLD is useless outside a transaction block: the cursor would survive
86 only to the completion of the statement. Therefore PostgreSQL reports
87 an error if such a command is used outside a transaction block. Use
88 BEGIN(7) and COMMIT(7) (or ROLLBACK(7)) to define a transaction block.
89
90 If WITH HOLD is specified and the transaction that created the cursor
91 successfully commits, the cursor can continue to be accessed by
92 subsequent transactions in the same session. (But if the creating
93 transaction is aborted, the cursor is removed.) A cursor created with
94 WITH HOLD is closed when an explicit CLOSE command is issued on it, or
95 the session ends. In the current implementation, the rows represented
96 by a held cursor are copied into a temporary file or memory area so
97 that they remain available for subsequent transactions.
98
99 WITH HOLD may not be specified when the query includes FOR UPDATE or
100 FOR SHARE.
101
102 The SCROLL option should be specified when defining a cursor that will
103 be used to fetch backwards. This is required by the SQL standard.
104 However, for compatibility with earlier versions, PostgreSQL will allow
105 backward fetches without SCROLL, if the cursor's query plan is simple
106 enough that no extra overhead is needed to support it. However,
107 application developers are advised not to rely on using backward
108 fetches from a cursor that has not been created with SCROLL. If NO
109 SCROLL is specified, then backward fetches are disallowed in any case.
110
111 Backward fetches are also disallowed when the query includes FOR UPDATE
112 or FOR SHARE; therefore SCROLL may not be specified in this case.
113
114 Caution
115 Scrollable and WITH HOLD cursors may give unexpected results if
116 they invoke any volatile functions (see Section 35.6, “Function
117 Volatility Categories”, in the documentation). When a previously
118 fetched row is re-fetched, the functions might be re-executed,
119 perhaps leading to results different from the first time. One
120 workaround for such cases is to declare the cursor WITH HOLD and
121 commit the transaction before reading any rows from it. This will
122 force the entire output of the cursor to be materialized in
123 temporary storage, so that volatile functions are executed exactly
124 once for each row.
125
126 If the cursor's query includes FOR UPDATE or FOR SHARE, then returned
127 rows are locked at the time they are first fetched, in the same way as
128 for a regular SELECT(7) command with these options. In addition, the
129 returned rows will be the most up-to-date versions; therefore these
130 options provide the equivalent of what the SQL standard calls a
131 “sensitive cursor”. (Specifying INSENSITIVE together with FOR UPDATE or
132 FOR SHARE is an error.)
133
134 Caution
135 It is generally recommended to use FOR UPDATE if the cursor is
136 intended to be used with UPDATE ... WHERE CURRENT OF or DELETE ...
137 WHERE CURRENT OF. Using FOR UPDATE prevents other sessions from
138 changing the rows between the time they are fetched and the time
139 they are updated. Without FOR UPDATE, a subsequent WHERE CURRENT OF
140 command will have no effect if the row was changed since the cursor
141 was created.
142
143 Another reason to use FOR UPDATE is that without it, a subsequent
144 WHERE CURRENT OF might fail if the cursor query does not meet the
145 SQL standard's rules for being “simply updatable” (in particular,
146 the cursor must reference just one table and not use grouping or
147 ORDER BY). Cursors that are not simply updatable might work, or
148 might not, depending on plan choice details; so in the worst case,
149 an application might work in testing and then fail in production.
150
151 The main reason not to use FOR UPDATE with WHERE CURRENT OF is if
152 you need the cursor to be scrollable, or to be insensitive to the
153 subsequent updates (that is, continue to show the old data). If
154 this is a requirement, pay close heed to the caveats shown above.
155
156 The SQL standard only makes provisions for cursors in embedded SQL. The
157 PostgreSQL server does not implement an OPEN statement for cursors; a
158 cursor is considered to be open when it is declared. However, ECPG, the
159 embedded SQL preprocessor for PostgreSQL, supports the standard SQL
160 cursor conventions, including those involving DECLARE and OPEN
161 statements.
162
163 You can see all available cursors by querying the pg_cursors system
164 view.
165
167 To declare a cursor:
168
169 DECLARE liahona CURSOR FOR SELECT * FROM films;
170
171 See FETCH(7) for more examples of cursor usage.
172
174 The SQL standard says that it is implementation-dependent whether
175 cursors are sensitive to concurrent updates of the underlying data by
176 default. In PostgreSQL, cursors are insensitive by default, and can be
177 made sensitive by specifying FOR UPDATE. Other products may work
178 differently.
179
180 The SQL standard allows cursors only in embedded SQL and in modules.
181 PostgreSQL permits cursors to be used interactively.
182
183 Binary cursors are a PostgreSQL extension.
184
186 CLOSE(7), FETCH(7), MOVE(7)
187
188
189
190PostgreSQL 9.2.24 2017-11-06 DECLARE(7)