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