1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>36.8.Cursors</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="plpgsql.html" title="Chapter36.PL/pgSQL - SQL Procedural Language">
<link rel="prev" href="plpgsql-control-structures.html" title="36.7.Control Structures">
<link rel="next" href="plpgsql-errors-and-messages.html" title="36.9.Errors and Messages">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="plpgsql-cursors"></a>36.8.Cursors</h2></div></div></div>
<a name="id726138"></a><p> Rather than executing a whole query at once, it is possible to set
up a <em class="firstterm">cursor</em> that encapsulates the query, and then read
the query result a few rows at a time. One reason for doing this is
to avoid memory overrun when the result contains a large number of
rows. (However, <span class="application">PL/pgSQL</span> users do not normally need
to worry about that, since <code class="literal">FOR</code> loops automatically use a cursor
internally to avoid memory problems.) A more interesting usage is to
return a reference to a cursor that a function has created, allowing the
caller to read the rows. This provides an efficient way to return
large row sets from functions.
</p>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="plpgsql-cursor-declarations"></a>36.8.1.Declaring Cursor Variables</h3></div></div></div>
<p> All access to cursors in <span class="application">PL/pgSQL</span> goes through
cursor variables, which are always of the special data type
<code class="type">refcursor</code>. One way to create a cursor variable
is just to declare it as a variable of type <code class="type">refcursor</code>.
Another way is to use the cursor declaration syntax,
which in general is:
</p>
<pre class="synopsis"><em class="replaceable"><code>name</code></em> CURSOR [<span class="optional"> ( <em class="replaceable"><code>arguments</code></em> ) </span>] FOR <em class="replaceable"><code>query</code></em>;</pre>
<p>
(<code class="literal">FOR</code> may be replaced by <code class="literal">IS</code> for
<span class="productname">Oracle</span> compatibility.)
<em class="replaceable"><code>arguments</code></em>, if specified, is a
comma-separated list of pairs <code class="literal"><em class="replaceable"><code>name</code></em>
<em class="replaceable"><code>datatype</code></em></code> that define names to be
replaced by parameter values in the given query. The actual
values to substitute for these names will be specified later,
when the cursor is opened.
</p>
<p> Some examples:
</p>
<pre class="programlisting">DECLARE
curs1 refcursor;
curs2 CURSOR FOR SELECT * FROM tenk1;
curs3 CURSOR (key integer) IS SELECT * FROM tenk1 WHERE unique1 = key;</pre>
<p>
All three of these variables have the data type <code class="type">refcursor</code>,
but the first may be used with any query, while the second has
a fully specified query already <em class="firstterm">bound</em> to it, and the last
has a parameterized query bound to it. (<code class="literal">key</code> will be
replaced by an integer parameter value when the cursor is opened.)
The variable <code class="literal">curs1</code>
is said to be <em class="firstterm">unbound</em> since it is not bound to
any particular query.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="plpgsql-cursor-opening"></a>36.8.2.Opening Cursors</h3></div></div></div>
<p> Before a cursor can be used to retrieve rows, it must be
<em class="firstterm">opened</em>. (This is the equivalent action to the SQL
command <code class="command">DECLARE CURSOR</code>.) <span class="application">PL/pgSQL</span> has
three forms of the <code class="command">OPEN</code> statement, two of which use unbound
cursor variables while the third uses a bound cursor variable.
</p>
<div class="sect3" lang="en">
<div class="titlepage"><div><div><h4 class="title">
<a name="id726358"></a>36.8.2.1.<code class="command">OPEN FOR</code> <em class="replaceable"><code>query</code></em></h4></div></div></div>
<pre class="synopsis">OPEN <em class="replaceable"><code>unbound_cursor</code></em> FOR <em class="replaceable"><code>query</code></em>;</pre>
<p> The cursor variable is opened and given the specified query to
execute. The cursor cannot be open already, and it must have been
declared as an unbound cursor (that is, as a simple
<code class="type">refcursor</code> variable). The query must be a
<code class="command">SELECT</code>, or something else that returns rows
(such as <code class="command">EXPLAIN</code>). The query
is treated in the same way as other SQL commands in
<span class="application">PL/pgSQL</span>: <span class="application">PL/pgSQL</span>
variable names are substituted, and the query plan is cached for
possible reuse.
</p>
<p> An example:
</p>
<pre class="programlisting">OPEN curs1 FOR SELECT * FROM foo WHERE key = mykey;</pre>
<p>
</p>
</div>
<div class="sect3" lang="en">
<div class="titlepage"><div><div><h4 class="title">
<a name="id726434"></a>36.8.2.2.<code class="command">OPEN FOR EXECUTE</code></h4></div></div></div>
<pre class="synopsis">OPEN <em class="replaceable"><code>unbound_cursor</code></em> FOR EXECUTE <em class="replaceable"><code>query_string</code></em>;</pre>
<p> The cursor variable is opened and given the specified query to
execute. The cursor cannot be open already, and it must have been
declared as an unbound cursor (that is, as a simple
<code class="type">refcursor</code> variable). The query is specified as a string
expression, in the same way as in the <code class="command">EXECUTE</code>
command. As usual, this gives flexibility so the query can vary
from one run to the next.
</p>
<p> An example:
</p>
<pre class="programlisting">OPEN curs1 FOR EXECUTE 'SELECT * FROM ' || quote_ident($1);</pre>
<p>
</p>
</div>
<div class="sect3" lang="en">
<div class="titlepage"><div><div><h4 class="title">
<a name="id726488"></a>36.8.2.3.Opening a Bound Cursor</h4></div></div></div>
<pre class="synopsis">OPEN <em class="replaceable"><code>bound_cursor</code></em> [<span class="optional"> ( <em class="replaceable"><code>argument_values</code></em> ) </span>];</pre>
<p> This form of <code class="command">OPEN</code> is used to open a cursor
variable whose query was bound to it when it was declared. The
cursor cannot be open already. A list of actual argument value
expressions must appear if and only if the cursor was declared to
take arguments. These values will be substituted in the query.
The query plan for a bound cursor is always considered cacheable;
there is no equivalent of <code class="command">EXECUTE</code> in this case.
</p>
<p> Examples:
</p>
<pre class="programlisting">OPEN curs2;
OPEN curs3(42);</pre>
<p>
</p>
</div>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="plpgsql-cursor-using"></a>36.8.3.Using Cursors</h3></div></div></div>
<p> Once a cursor has been opened, it can be manipulated with the
statements described here.
</p>
<p> These manipulations need not occur in the same function that
opened the cursor to begin with. You can return a <code class="type">refcursor</code>
value out of a function and let the caller operate on the cursor.
(Internally, a <code class="type">refcursor</code> value is simply the string name
of a so-called portal containing the active query for the cursor. This name
can be passed around, assigned to other <code class="type">refcursor</code> variables,
and so on, without disturbing the portal.)
</p>
<p> All portals are implicitly closed at transaction end. Therefore
a <code class="type">refcursor</code> value is usable to reference an open cursor
only until the end of the transaction.
</p>
<div class="sect3" lang="en">
<div class="titlepage"><div><div><h4 class="title">
<a name="id726588"></a>36.8.3.1.<code class="literal">FETCH</code></h4></div></div></div>
<pre class="synopsis">FETCH <em class="replaceable"><code>cursor</code></em> INTO <em class="replaceable"><code>target</code></em>;</pre>
<p> <code class="command">FETCH</code> retrieves the next row from the
cursor into a target, which may be a row variable, a record
variable, or a comma-separated list of simple variables, just like
<code class="command">SELECT INTO</code>. As with <code class="command">SELECT
INTO</code>, the special variable <code class="literal">FOUND</code> may
be checked to see whether a row was obtained or not.
</p>
<p> An example:
</p>
<pre class="programlisting">FETCH curs1 INTO rowvar;
FETCH curs2 INTO foo, bar, baz;</pre>
<p>
</p>
</div>
<div class="sect3" lang="en">
<div class="titlepage"><div><div><h4 class="title">
<a name="id726652"></a>36.8.3.2.<code class="literal">CLOSE</code></h4></div></div></div>
<pre class="synopsis">CLOSE <em class="replaceable"><code>cursor</code></em>;</pre>
<p> <code class="command">CLOSE</code> closes the portal underlying an open
cursor. This can be used to release resources earlier than end of
transaction, or to free up the cursor variable to be opened again.
</p>
<p> An example:
</p>
<pre class="programlisting">CLOSE curs1;</pre>
<p>
</p>
</div>
<div class="sect3" lang="en">
<div class="titlepage"><div><div><h4 class="title">
<a name="id726690"></a>36.8.3.3.Returning Cursors</h4></div></div></div>
<p> <span class="application">PL/pgSQL</span> functions can return cursors to the
caller. This is useful to return multiple rows or columns,
especially with very large result sets. To do this, the function
opens the cursor and returns the cursor name to the caller (or simply
opens the cursor using a portal name specified by or otherwise known
to the caller). The caller can then fetch rows from the cursor. The
cursor can be closed by the caller, or it will be closed automatically
when the transaction closes.
</p>
<p> The portal name used for a cursor can be specified by the
programmer or automatically generated. To specify a portal name,
simply assign a string to the <code class="type">refcursor</code> variable before
opening it. The string value of the <code class="type">refcursor</code> variable
will be used by <code class="command">OPEN</code> as the name of the underlying portal.
However, if the <code class="type">refcursor</code> variable is null,
<code class="command">OPEN</code> automatically generates a name that does not
conflict with any existing portal, and assigns it to the
<code class="type">refcursor</code> variable.
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> A bound cursor variable is initialized to the string value
representing its name, so that the portal name is the same as
the cursor variable name, unless the programmer overrides it
by assignment before opening the cursor. But an unbound cursor
variable defaults to the null value initially, so it will receive
an automatically-generated unique name, unless overridden.
</p>
</div>
<p> The following example shows one way a cursor name can be supplied by
the caller:
</p>
<pre class="programlisting">CREATE TABLE test (col text);
INSERT INTO test VALUES ('123');
CREATE FUNCTION reffunc(refcursor) RETURNS refcursor AS '
BEGIN
OPEN $1 FOR SELECT col FROM test;
RETURN $1;
END;
' LANGUAGE plpgsql;
BEGIN;
SELECT reffunc('funccursor');
FETCH ALL IN funccursor;
COMMIT;</pre>
<p>
</p>
<p> The following example uses automatic cursor name generation:
</p>
<pre class="programlisting">CREATE FUNCTION reffunc2() RETURNS refcursor AS '
DECLARE
ref refcursor;
BEGIN
OPEN ref FOR SELECT col FROM test;
RETURN ref;
END;
' LANGUAGE plpgsql;
BEGIN;
SELECT reffunc2();
reffunc2
--------------------
<unnamed cursor 1>
(1 row)
FETCH ALL IN "<unnamed cursor 1>";
COMMIT;</pre>
<p>
</p>
<p> The following example shows one way to return multiple cursors
from a single function:
</p>
<pre class="programlisting">CREATE FUNCTION myfunc(refcursor, refcursor) RETURNS SETOF refcursor AS $$
BEGIN
OPEN $1 FOR SELECT * FROM table_1;
RETURN NEXT $1;
OPEN $2 FOR SELECT * FROM table_2;
RETURN NEXT $2;
END;
$$ LANGUAGE plpgsql;
-- need to be in a transaction to use cursors.
BEGIN;
SELECT * FROM myfunc('a', 'b');
FETCH ALL FROM a;
FETCH ALL FROM b;
COMMIT;</pre>
<p>
</p>
</div>
</div>
</div></body>
</html>
|