1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>DECLARE</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="sql-deallocate.html" title="DEALLOCATE" /><link rel="next" href="sql-delete.html" title="DELETE" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">DECLARE</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="sql-deallocate.html" title="DEALLOCATE">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><th width="60%" align="center">SQL Commands</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="sql-delete.html" title="DELETE">Next</a></td></tr></table><hr /></div><div class="refentry" id="SQL-DECLARE"><div class="titlepage"></div><a id="id-1.9.3.99.1" class="indexterm"></a><a id="id-1.9.3.99.2" class="indexterm"></a><a id="id-1.9.3.99.3" class="indexterm"></a><div class="refnamediv"><h2><span class="refentrytitle">DECLARE</span></h2><p>DECLARE — define a cursor</p></div><div class="refsynopsisdiv"><h2>Synopsis</h2><pre class="synopsis">
3 DECLARE <em class="replaceable"><code>name</code></em> [ BINARY ] [ ASENSITIVE | INSENSITIVE ] [ [ NO ] SCROLL ]
4 CURSOR [ { WITH | WITHOUT } HOLD ] FOR <em class="replaceable"><code>query</code></em>
5 </pre></div><div class="refsect1" id="id-1.9.3.99.7"><h2>Description</h2><p>
6 <code class="command">DECLARE</code> allows a user to create cursors, which
7 can be used to retrieve
8 a small number of rows at a time out of a larger query.
9 After the cursor is created, rows are fetched from it using
10 <a class="link" href="sql-fetch.html" title="FETCH"><code class="command">FETCH</code></a>.
11 </p><div class="note"><h3 class="title">Note</h3><p>
12 This page describes usage of cursors at the SQL command level.
13 If you are trying to use cursors inside a <span class="application">PL/pgSQL</span>
14 function, the rules are different —
15 see <a class="xref" href="plpgsql-cursors.html" title="41.7. Cursors">Section 41.7</a>.
16 </p></div></div><div class="refsect1" id="id-1.9.3.99.8"><h2>Parameters</h2><div class="variablelist"><dl class="variablelist"><dt><span class="term"><em class="replaceable"><code>name</code></em></span></dt><dd><p>
17 The name of the cursor to be created.
18 This must be different from any other active cursor name in the
20 </p></dd><dt><span class="term"><code class="literal">BINARY</code></span></dt><dd><p>
21 Causes the cursor to return data in binary rather than in text format.
22 </p></dd><dt><span class="term"><code class="literal">ASENSITIVE</code><br /></span><span class="term"><code class="literal">INSENSITIVE</code></span></dt><dd><p>
23 Cursor sensitivity determines whether changes to the data underlying the
24 cursor, done in the same transaction, after the cursor has been
25 declared, are visible in the cursor. <code class="literal">INSENSITIVE</code>
26 means they are not visible, <code class="literal">ASENSITIVE</code> means the
27 behavior is implementation-dependent. A third behavior,
28 <code class="literal">SENSITIVE</code>, meaning that such changes are visible in
29 the cursor, is not available in <span class="productname">PostgreSQL</span>.
30 In <span class="productname">PostgreSQL</span>, all cursors are insensitive;
31 so these key words have no effect and are only accepted for
32 compatibility with the SQL standard.
34 Specifying <code class="literal">INSENSITIVE</code> together with <code class="literal">FOR
35 UPDATE</code> or <code class="literal">FOR SHARE</code> is an error.
36 </p></dd><dt><span class="term"><code class="literal">SCROLL</code><br /></span><span class="term"><code class="literal">NO SCROLL</code></span></dt><dd><p><code class="literal">SCROLL</code> specifies that the cursor can be used
37 to retrieve rows in a nonsequential fashion (e.g.,
38 backward). Depending upon the complexity of the query's
39 execution plan, specifying <code class="literal">SCROLL</code> might impose
40 a performance penalty on the query's execution time.
41 <code class="literal">NO SCROLL</code> specifies that the cursor cannot be
42 used to retrieve rows in a nonsequential fashion. The default is to
43 allow scrolling in some cases; this is not the same as specifying
44 <code class="literal">SCROLL</code>. See <a class="xref" href="sql-declare.html#SQL-DECLARE-NOTES" title="Notes">Notes</a>
46 </p></dd><dt><span class="term"><code class="literal">WITH HOLD</code><br /></span><span class="term"><code class="literal">WITHOUT HOLD</code></span></dt><dd><p><code class="literal">WITH HOLD</code> specifies that the cursor can
47 continue to be used after the transaction that created it
48 successfully commits. <code class="literal">WITHOUT HOLD</code> specifies
49 that the cursor cannot be used outside of the transaction that
50 created it. If neither <code class="literal">WITHOUT HOLD</code> nor
51 <code class="literal">WITH HOLD</code> is specified, <code class="literal">WITHOUT
52 HOLD</code> is the default.
53 </p></dd><dt><span class="term"><em class="replaceable"><code>query</code></em></span></dt><dd><p>
54 A <a class="link" href="sql-select.html" title="SELECT"><code class="command">SELECT</code></a> or
55 <a class="link" href="sql-values.html" title="VALUES"><code class="command">VALUES</code></a> command
56 which will provide the rows to be returned by the cursor.
57 </p></dd></dl></div><p>
58 The key words <code class="literal">ASENSITIVE</code>, <code class="literal">BINARY</code>,
59 <code class="literal">INSENSITIVE</code>, and <code class="literal">SCROLL</code> can
61 </p></div><div class="refsect1" id="SQL-DECLARE-NOTES"><h2>Notes</h2><p>
62 Normal cursors return data in text format, the same as a
63 <code class="command">SELECT</code> would produce. The <code class="literal">BINARY</code> option
64 specifies that the cursor should return data in binary format.
65 This reduces conversion effort for both the server and client,
66 at the cost of more programmer effort to deal with platform-dependent
68 As an example, if a query returns a value of one from an integer column,
69 you would get a string of <code class="literal">1</code> with a default cursor,
70 whereas with a binary cursor you would get
71 a 4-byte field containing the internal representation of the value
72 (in big-endian byte order).
74 Binary cursors should be used carefully. Many applications,
75 including <span class="application">psql</span>, are not prepared to
76 handle binary cursors and expect data to come back in the text
78 </p><div class="note"><h3 class="title">Note</h3><p>
79 When the client application uses the <span class="quote">“<span class="quote">extended query</span>”</span> protocol
80 to issue a <code class="command">FETCH</code> command, the Bind protocol message
81 specifies whether data is to be retrieved in text or binary format.
82 This choice overrides the way that the cursor is defined. The concept
83 of a binary cursor as such is thus obsolete when using extended query
84 protocol — any cursor can be treated as either text or binary.
86 Unless <code class="literal">WITH HOLD</code> is specified, the cursor
87 created by this command can only be used within the current
88 transaction. Thus, <code class="command">DECLARE</code> without <code class="literal">WITH
89 HOLD</code> is useless outside a transaction block: the cursor would
90 survive only to the completion of the statement. Therefore
91 <span class="productname">PostgreSQL</span> reports an error if such a
92 command is used outside a transaction block.
94 <a class="link" href="sql-begin.html" title="BEGIN"><code class="command">BEGIN</code></a> and
95 <a class="link" href="sql-commit.html" title="COMMIT"><code class="command">COMMIT</code></a>
96 (or <a class="link" href="sql-rollback.html" title="ROLLBACK"><code class="command">ROLLBACK</code></a>)
97 to define a transaction block.
99 If <code class="literal">WITH HOLD</code> is specified and the transaction
100 that created the cursor successfully commits, the cursor can
101 continue to be accessed by subsequent transactions in the same
102 session. (But if the creating transaction is aborted, the cursor
103 is removed.) A cursor created with <code class="literal">WITH HOLD</code>
104 is closed when an explicit <code class="command">CLOSE</code> command is
105 issued on it, or the session ends. In the current implementation,
106 the rows represented by a held cursor are copied into a temporary
107 file or memory area so that they remain available for subsequent
110 <code class="literal">WITH HOLD</code> may not be specified when the query
111 includes <code class="literal">FOR UPDATE</code> or <code class="literal">FOR SHARE</code>.
113 The <code class="literal">SCROLL</code> option should be specified when defining a
114 cursor that will be used to fetch backwards. This is required by
115 the SQL standard. However, for compatibility with earlier
116 versions, <span class="productname">PostgreSQL</span> will allow
117 backward fetches without <code class="literal">SCROLL</code>, if the cursor's query
118 plan is simple enough that no extra overhead is needed to support
119 it. However, application developers are advised not to rely on
120 using backward fetches from a cursor that has not been created
121 with <code class="literal">SCROLL</code>. If <code class="literal">NO SCROLL</code> is
122 specified, then backward fetches are disallowed in any case.
124 Backward fetches are also disallowed when the query
125 includes <code class="literal">FOR UPDATE</code> or <code class="literal">FOR SHARE</code>; therefore
126 <code class="literal">SCROLL</code> may not be specified in this case.
127 </p><div class="caution"><h3 class="title">Caution</h3><p>
128 Scrollable cursors may give unexpected
129 results if they invoke any volatile functions (see <a class="xref" href="xfunc-volatility.html" title="36.7. Function Volatility Categories">Section 36.7</a>). When a previously fetched row is
130 re-fetched, the functions might be re-executed, perhaps leading to
131 results different from the first time. It's best to
132 specify <code class="literal">NO SCROLL</code> for a query involving volatile
133 functions. If that is not practical, one workaround
134 is to declare the cursor <code class="literal">SCROLL WITH HOLD</code> and commit the
135 transaction before reading any rows from it. This will force the
136 entire output of the cursor to be materialized in temporary storage,
137 so that volatile functions are executed exactly once for each row.
139 If the cursor's query includes <code class="literal">FOR UPDATE</code> or <code class="literal">FOR
140 SHARE</code>, then returned rows are locked at the time they are first
141 fetched, in the same way as for a regular
142 <a class="link" href="sql-select.html" title="SELECT"><code class="command">SELECT</code></a> command with
144 In addition, the returned rows will be the most up-to-date versions.
145 </p><div class="caution"><h3 class="title">Caution</h3><p>
146 It is generally recommended to use <code class="literal">FOR UPDATE</code> if the cursor
147 is intended to be used with <code class="command">UPDATE ... WHERE CURRENT OF</code> or
148 <code class="command">DELETE ... WHERE CURRENT OF</code>. Using <code class="literal">FOR UPDATE</code>
149 prevents other sessions from changing the rows between the time they are
150 fetched and the time they are updated. Without <code class="literal">FOR UPDATE</code>,
151 a subsequent <code class="literal">WHERE CURRENT OF</code> command will have no effect if
152 the row was changed since the cursor was created.
154 Another reason to use <code class="literal">FOR UPDATE</code> is that without it, a
155 subsequent <code class="literal">WHERE CURRENT OF</code> might fail if the cursor query
156 does not meet the SQL standard's rules for being <span class="quote">“<span class="quote">simply
157 updatable</span>”</span> (in particular, the cursor must reference just one table
158 and not use grouping or <code class="literal">ORDER BY</code>). Cursors
159 that are not simply updatable might work, or might not, depending on plan
160 choice details; so in the worst case, an application might work in testing
161 and then fail in production. If <code class="literal">FOR UPDATE</code> is
162 specified, the cursor is guaranteed to be updatable.
164 The main reason not to use <code class="literal">FOR UPDATE</code> with <code class="literal">WHERE
165 CURRENT OF</code> is if you need the cursor to be scrollable, or to be
166 isolated from concurrent updates (that is, continue to show the old
167 data). If this is a requirement, pay close heed to the caveats shown
170 The SQL standard only makes provisions for cursors in embedded
171 <acronym class="acronym">SQL</acronym>. The <span class="productname">PostgreSQL</span>
172 server does not implement an <code class="command">OPEN</code> statement for
173 cursors; a cursor is considered to be open when it is declared.
174 However, <span class="application">ECPG</span>, the embedded SQL
175 preprocessor for <span class="productname">PostgreSQL</span>, supports
176 the standard SQL cursor conventions, including those involving
177 <code class="command">DECLARE</code> and <code class="command">OPEN</code> statements.
179 The server data structure underlying an open cursor is called a
180 <em class="firstterm">portal</em>. Portal names are exposed in the
181 client protocol: a client can fetch rows directly from an open
182 portal, if it knows the portal name. When creating a cursor with
183 <code class="command">DECLARE</code>, the portal name is the same as the
186 You can see all available cursors by querying the <a class="link" href="view-pg-cursors.html" title="53.7. pg_cursors"><code class="structname">pg_cursors</code></a>
188 </p></div><div class="refsect1" id="id-1.9.3.99.10"><h2>Examples</h2><p>
190 </p><pre class="programlisting">
191 DECLARE liahona CURSOR FOR SELECT * FROM films;
193 See <a class="xref" href="sql-fetch.html" title="FETCH"><span class="refentrytitle">FETCH</span></a> for more
194 examples of cursor usage.
195 </p></div><div class="refsect1" id="id-1.9.3.99.11"><h2>Compatibility</h2><p>
196 The SQL standard allows cursors only in embedded
197 <acronym class="acronym">SQL</acronym> and in modules. <span class="productname">PostgreSQL</span>
198 permits cursors to be used interactively.
200 According to the SQL standard, changes made to insensitive cursors by
201 <code class="literal">UPDATE ... WHERE CURRENT OF</code> and <code class="literal">DELETE
202 ... WHERE CURRENT OF</code> statements are visible in that same
203 cursor. <span class="productname">PostgreSQL</span> treats these statements like
204 all other data changing statements in that they are not visible in
207 Binary cursors are a <span class="productname">PostgreSQL</span>
209 </p></div><div class="refsect1" id="id-1.9.3.99.12"><h2>See Also</h2><span class="simplelist"><a class="xref" href="sql-close.html" title="CLOSE"><span class="refentrytitle">CLOSE</span></a>, <a class="xref" href="sql-fetch.html" title="FETCH"><span class="refentrytitle">FETCH</span></a>, <a class="xref" href="sql-move.html" title="MOVE"><span class="refentrytitle">MOVE</span></a></span></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="sql-deallocate.html" title="DEALLOCATE">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="sql-delete.html" title="DELETE">Next</a></td></tr><tr><td width="40%" align="left" valign="top">DEALLOCATE </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> DELETE</td></tr></table></div></body></html>