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