1DECLARE(7)               PostgreSQL 16.1 Documentation              DECLARE(7)
2
3
4

NAME

6       DECLARE - define a cursor
7

SYNOPSIS

9       DECLARE name [ BINARY ] [ ASENSITIVE | INSENSITIVE ] [ [ NO ] SCROLL ]
10           CURSOR [ { WITH | WITHOUT } HOLD ] FOR query
11

DESCRIPTION

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

PARAMETERS

23       name
24           The name of the cursor to be created. This must be different from
25           any other active cursor name in the session.
26
27       BINARY
28           Causes the cursor to return data in binary rather than in text
29           format.
30
31       ASENSITIVE
32       INSENSITIVE
33           Cursor sensitivity determines whether changes to the data
34           underlying the cursor, done in the same transaction, after the
35           cursor has been declared, are visible in the cursor.  INSENSITIVE
36           means they are not visible, ASENSITIVE means the behavior is
37           implementation-dependent. A third behavior, SENSITIVE, meaning that
38           such changes are visible in the cursor, is not available in
39           PostgreSQL. In PostgreSQL, all cursors are insensitive; so these
40           key words have no effect and are only accepted for compatibility
41           with the SQL standard.
42
43           Specifying INSENSITIVE together with FOR UPDATE or FOR SHARE is an
44           error.
45
46       SCROLL
47       NO SCROLL
48           SCROLL specifies that the cursor can be used to retrieve rows in a
49           nonsequential fashion (e.g., backward). Depending upon the
50           complexity of the query's execution plan, specifying SCROLL might
51           impose a performance penalty on the query's execution time.  NO
52           SCROLL specifies that the cursor cannot be used to retrieve rows in
53           a nonsequential fashion. The default is to allow scrolling in some
54           cases; this is not the same as specifying SCROLL. See Notes below
55           for details.
56
57       WITH HOLD
58       WITHOUT HOLD
59           WITH HOLD specifies that the cursor can continue to be used after
60           the transaction that created it successfully commits.  WITHOUT HOLD
61           specifies that the cursor cannot be used outside of the transaction
62           that created it. If neither WITHOUT HOLD nor WITH HOLD is
63           specified, WITHOUT HOLD is the default.
64
65       query
66           A SELECT or VALUES command which will provide the rows to be
67           returned by the cursor.
68
69       The key words ASENSITIVE, BINARY, INSENSITIVE, and SCROLL can appear in
70       any order.
71

NOTES

73       Normal cursors return data in text format, the same as a SELECT would
74       produce. The BINARY option specifies that the cursor should return data
75       in binary format. This reduces conversion effort for both the server
76       and client, at the cost of more programmer effort to deal with
77       platform-dependent binary data formats. As an example, if a query
78       returns a value of one from an integer column, you would get a string
79       of 1 with a default cursor, whereas with a binary cursor you would get
80       a 4-byte field containing the internal representation of the value (in
81       big-endian byte order).
82
83       Binary cursors should be used carefully. Many applications, including
84       psql, are not prepared to handle binary cursors and expect data to come
85       back in the text format.
86
87           Note
88           When the client application uses the “extended query” protocol to
89           issue a FETCH command, the Bind protocol message specifies whether
90           data is to be retrieved in text or binary format. This choice
91           overrides the way that the cursor is defined. The concept of a
92           binary cursor as such is thus obsolete when using extended query
93           protocol — any cursor can be treated as either text or binary.
94
95       Unless WITH HOLD is specified, the cursor created by this command can
96       only be used within the current transaction. Thus, DECLARE without WITH
97       HOLD is useless outside a transaction block: the cursor would survive
98       only to the completion of the statement. Therefore PostgreSQL reports
99       an error if such a command is used outside a transaction block. Use
100       BEGIN and COMMIT (or ROLLBACK) to define a transaction block.
101
102       If WITH HOLD is specified and the transaction that created the cursor
103       successfully commits, the cursor can continue to be accessed by
104       subsequent transactions in the same session. (But if the creating
105       transaction is aborted, the cursor is removed.) A cursor created with
106       WITH HOLD is closed when an explicit CLOSE command is issued on it, or
107       the session ends. In the current implementation, the rows represented
108       by a held cursor are copied into a temporary file or memory area so
109       that they remain available for subsequent transactions.
110
111       WITH HOLD may not be specified when the query includes FOR UPDATE or
112       FOR SHARE.
113
114       The SCROLL option should be specified when defining a cursor that will
115       be used to fetch backwards. This is required by the SQL standard.
116       However, for compatibility with earlier versions, PostgreSQL will allow
117       backward fetches without SCROLL, if the cursor's query plan is simple
118       enough that no extra overhead is needed to support it. However,
119       application developers are advised not to rely on using backward
120       fetches from a cursor that has not been created with SCROLL. If NO
121       SCROLL is specified, then backward fetches are disallowed in any case.
122
123       Backward fetches are also disallowed when the query includes FOR UPDATE
124       or FOR SHARE; therefore SCROLL may not be specified in this case.
125
126           Caution
127           Scrollable cursors may give unexpected results if they invoke any
128           volatile functions (see Section 38.7). When a previously fetched
129           row is re-fetched, the functions might be re-executed, perhaps
130           leading to results different from the first time. It's best to
131           specify NO SCROLL for a query involving volatile functions. If that
132           is not practical, one workaround is to declare the cursor SCROLL
133           WITH HOLD and commit the transaction before reading any rows from
134           it. This will force the entire output of the cursor to be
135           materialized in temporary storage, so that volatile functions are
136           executed exactly once for each row.
137
138       If the cursor's query includes FOR UPDATE or FOR SHARE, then returned
139       rows are locked at the time they are first fetched, in the same way as
140       for a regular SELECT command with these options. In addition, the
141       returned rows will be the most up-to-date versions.
142
143           Caution
144           It is generally recommended to use FOR UPDATE if the cursor is
145           intended to be used with UPDATE ... WHERE CURRENT OF or DELETE ...
146           WHERE CURRENT OF. Using FOR UPDATE prevents other sessions from
147           changing the rows between the time they are fetched and the time
148           they are updated. Without FOR UPDATE, a subsequent WHERE CURRENT OF
149           command will have no effect if the row was changed since the cursor
150           was created.
151
152           Another reason to use FOR UPDATE is that without it, a subsequent
153           WHERE CURRENT OF might fail if the cursor query does not meet the
154           SQL standard's rules for being “simply updatable” (in particular,
155           the cursor must reference just one table and not use grouping or
156           ORDER BY). Cursors that are not simply updatable might work, or
157           might not, depending on plan choice details; so in the worst case,
158           an application might work in testing and then fail in production.
159           If FOR UPDATE is specified, the cursor is guaranteed to be
160           updatable.
161
162           The main reason not to use FOR UPDATE with WHERE CURRENT OF is if
163           you need the cursor to be scrollable, or to be isolated from
164           concurrent updates (that is, continue to show the old data). If
165           this is a requirement, pay close heed to the caveats shown above.
166
167       The SQL standard only makes provisions for cursors in embedded SQL. The
168       PostgreSQL server does not implement an OPEN statement for cursors; a
169       cursor is considered to be open when it is declared. However, ECPG, the
170       embedded SQL preprocessor for PostgreSQL, supports the standard SQL
171       cursor conventions, including those involving DECLARE and OPEN
172       statements.
173
174       The server data structure underlying an open cursor is called a portal.
175       Portal names are exposed in the client protocol: a client can fetch
176       rows directly from an open portal, if it knows the portal name. When
177       creating a cursor with DECLARE, the portal name is the same as the
178       cursor name.
179
180       You can see all available cursors by querying the pg_cursors system
181       view.
182

EXAMPLES

184       To declare a cursor:
185
186           DECLARE liahona CURSOR FOR SELECT * FROM films;
187
188       See FETCH(7) for more examples of cursor usage.
189

COMPATIBILITY

191       The SQL standard allows cursors only in embedded SQL and in modules.
192       PostgreSQL permits cursors to be used interactively.
193
194       According to the SQL standard, changes made to insensitive cursors by
195       UPDATE ... WHERE CURRENT OF and DELETE ... WHERE CURRENT OF statements
196       are visible in that same cursor.  PostgreSQL treats these statements
197       like all other data changing statements in that they are not visible in
198       insensitive cursors.
199
200       Binary cursors are a PostgreSQL extension.
201

SEE ALSO

203       CLOSE(7), FETCH(7), MOVE(7)
204
205
206
207PostgreSQL 16.1                      2023                           DECLARE(7)
Impressum