aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/fetch.sgml
blob: a1f3b13719fae9d3d5d46c422cec4d7ba1346050 (plain)
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
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/fetch.sgml,v 1.28 2003/03/27 16:51:27 momjian Exp $
PostgreSQL documentation
-->

<refentry id="SQL-FETCH">
 <refmeta>
  <refentrytitle id="SQL-FETCH-TITLE">FETCH</refentrytitle>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>
 <refnamediv>
  <refname>
   FETCH
  </refname>
  <refpurpose>
   retrieve rows from a query using a cursor
  </refpurpose>
 </refnamediv>
 <refsynopsisdiv>
  <refsynopsisdivinfo>
   <date>2003-03-11</date>
  </refsynopsisdivinfo>
  <synopsis>
FETCH [ <replaceable class="PARAMETER">direction</replaceable> { FROM | IN } ] <replaceable class="PARAMETER">cursor</replaceable>

where <replaceable class="PARAMETER">direction</replaceable> can be empty or one of:

    NEXT
    PRIOR
    FIRST
    LAST
    ABSOLUTE <replaceable class="PARAMETER">count</replaceable>
    RELATIVE <replaceable class="PARAMETER">count</replaceable>
    <replaceable class="PARAMETER">count</replaceable>
    ALL
    FORWARD
    FORWARD <replaceable class="PARAMETER">count</replaceable>
    FORWARD ALL
    BACKWARD
    BACKWARD <replaceable class="PARAMETER">count</replaceable>
    BACKWARD ALL
  </synopsis>

  <refsect2 id="R2-SQL-FETCH-1">
   <refsect2info>
    <date>2003-03-11</date>
   </refsect2info>
   <title>
    Inputs
   </title>
   <para>

    <variablelist>
     <varlistentry>
      <term><replaceable class="PARAMETER">direction</replaceable></term>
      <listitem>
       <para>
	<replaceable class="PARAMETER">direction</replaceable>
	defines the fetch direction and number of rows to fetch.
	It can be one of the following:

	<variablelist>
	 <varlistentry>
	  <term>NEXT</term>
	  <listitem>
	   <para>
	    fetch next row. This is the default
	    if <replaceable class="PARAMETER">direction</replaceable> is omitted.
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>PRIOR</term>
	  <listitem>
	   <para>
	    fetch prior row.
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>FIRST</term>
	  <listitem>
	   <para>
	    fetch first row of query (same as ABSOLUTE 1).
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>LAST</term>
	  <listitem>
	   <para>
	    fetch last row of query (same as ABSOLUTE -1).
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>ABSOLUTE <replaceable class="PARAMETER">count</replaceable></term>
	  <listitem>
	   <para>
	    fetch the <replaceable class="PARAMETER">count</replaceable>'th
	    row of query, or the
	    abs(<replaceable class="PARAMETER">count</replaceable>)'th row
	    from the end if
	    <replaceable class="PARAMETER">count</replaceable> &lt; 0.
	    Position before first row or after last row
	    if <replaceable class="PARAMETER">count</replaceable> is out of
	    range; in particular, ABSOLUTE 0 positions before first row.
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>RELATIVE <replaceable class="PARAMETER">count</replaceable></term>
	  <listitem>
	   <para>
	    fetch the <replaceable class="PARAMETER">count</replaceable>'th
	    succeeding row, or the
	    abs(<replaceable class="PARAMETER">count</replaceable>)'th prior
	    row if <replaceable class="PARAMETER">count</replaceable> &lt; 0.
	    RELATIVE 0 re-fetches current row, if any.
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term><replaceable class="PARAMETER">count</replaceable></term>
	  <listitem>
	   <para>
	    fetch the next <replaceable class="PARAMETER">count</replaceable>
	    rows (same as FORWARD <replaceable class="PARAMETER">count</replaceable>).
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>ALL</term>
	  <listitem>
	   <para>
	    fetch all remaining rows (same as FORWARD ALL).
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>FORWARD</term>
	  <listitem>
	   <para>
	    fetch next row (same as NEXT).
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>FORWARD <replaceable class="PARAMETER">count</replaceable></term>
	  <listitem>
	   <para>
	    fetch next <replaceable class="PARAMETER">count</replaceable>
	    rows.  FORWARD 0 re-fetches current row.
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>FORWARD ALL</term>
	  <listitem>
	   <para>
	    fetch all remaining rows.
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>BACKWARD</term>
	  <listitem>
	   <para>
	    fetch prior row (same as PRIOR).
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>BACKWARD <replaceable class="PARAMETER">count</replaceable></term>
	  <listitem>
	   <para>
	    fetch prior <replaceable class="PARAMETER">count</replaceable>
	    rows (scanning backwards).  BACKWARD 0 re-fetches current row.
	   </para>
	  </listitem>
	 </varlistentry>

	 <varlistentry>
	  <term>BACKWARD ALL</term>
	  <listitem>
	   <para>
	    fetch all prior rows (scanning backwards).
	   </para>
	  </listitem>
	 </varlistentry>

	</variablelist>
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">count</replaceable></term>
      <listitem>
       <para>
	<replaceable class="PARAMETER">count</replaceable>
	is a possibly-signed integer constant, determining the location
	or number of rows to fetch.  For FORWARD and BACKWARD cases,
	specifying a negative <replaceable
	class="PARAMETER">count</replaceable>
	is equivalent to changing the sense of FORWARD and BACKWARD.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">cursor</replaceable></term>
      <listitem>
       <para>
	An open cursor's name.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
  </refsect2>

  <refsect2 id="R2-SQL-FETCH-2">
   <refsect2info>
    <date>2003-03-11</date>
   </refsect2info>
   <title>
    Outputs
   </title>
   <para>
    <command>FETCH</command> returns rows from the result of the query defined
    by the specified cursor.
    The following messages will be returned if the query fails:

    <variablelist>
     <varlistentry>
      <term><computeroutput>
WARNING:  PerformPortalFetch: portal "<replaceable class="PARAMETER">cursor</replaceable>" not found
       </computeroutput></term>
      <listitem>
       <para>
        There is no cursor with the specified name.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
  </refsect2>
 </refsynopsisdiv>

 <refsect1 id="R1-SQL-FETCH-1">
  <refsect1info>
   <date>2003-03-11</date>
  </refsect1info>
  <title>
   Description
  </title>

  <para>
   <command>FETCH</command> retrieves rows using a cursor.
  </para>

  <para>
   A cursor has an associated <firstterm>position</> that is used by
   <command>FETCH</>.  The cursor position can be before the first row of the
   query result, or on any particular row of the result, or after the last row
   of the result.  When created, a cursor is positioned before the first row.
   After fetching some rows, the cursor is positioned on the row most recently
   retrieved.  If <command>FETCH</> runs off the end of the available rows
   then the cursor is left positioned after the last row, or before the first
   row if fetching backward.  <command>FETCH ALL</> or <command>FETCH BACKWARD
   ALL</> will always leave the cursor positioned after the last row or before
   the first row.
  </para>

  <para>
   The SQL-compatible forms (NEXT, PRIOR, FIRST, LAST, ABSOLUTE, RELATIVE)
   fetch a single row after moving the cursor appropriately.  If there is
   no such row, an empty result is returned, and the cursor is left positioned
   before the first row or after the last row as appropriate.
  </para>

  <para>
   The forms using FORWARD and BACKWARD are not in the SQL standard, but
   are <productname>PostgreSQL</productname> extensions.  These forms
   retrieve the indicated number of rows moving in the forward or backward
   direction, leaving the cursor positioned on the last-returned row
   (or after/before all rows, if the <replaceable
   class="PARAMETER">count</replaceable> exceeds the number of rows
   available).
  </para>

   <tip>
    <para>
     RELATIVE 0, FORWARD 0, and BACKWARD 0 all request
     fetching the current row without moving the
     cursor --- that is, re-fetching the most recently fetched row.
     This will succeed unless the cursor is positioned before the
     first row or after the last row; in which case, no row is returned.
    </para>
   </tip>

  <refsect2 id="R2-SQL-FETCH-3">
   <refsect2info>
    <date>2003-03-11</date>
   </refsect2info>
   <title>
    Notes
   </title>

   <para>
    The cursor should be declared with the SCROLL option if one intends to
    use any variants of <command>FETCH</> other than <command>FETCH NEXT</>
    or <command>FETCH FORWARD</> with a positive count.  For simple queries
    <productname>PostgreSQL</productname> will allow backwards fetch from
    cursors not declared with SCROLL, but this behavior is best not
    relied on. If the cursor is declared with NO SCROLL, no backward
    fetches are allowed.
   </para>

   <para>
    ABSOLUTE fetches are not any faster than navigating to the desired row
    with a relative move: the underlying implementation must traverse all
    the intermediate rows anyway.  Negative absolute fetches are even worse:
    the query must be read to the end to find the last row, and then
    traversed backward from there.  However, rewinding to the start of the
    query (as with FETCH ABSOLUTE 0) is fast.
   </para>

   <para>
    Updating data via a cursor is not supported by
    <productname>PostgreSQL</productname>, because mapping cursor
    updates back to base tables is not generally possible, as is also
    the case with view updates.  Consequently, users must issue
    explicit <command>UPDATE</command> commands to replace data.
   </para>

   <para>
    <xref linkend="sql-declare" endterm="sql-declare-title">
    is used to define a cursor.
    Use
    <xref linkend="sql-move" endterm="sql-move-title">
    to change cursor position without retrieving data.
   </para>
  </refsect2>
 </refsect1>

 <refsect1 id="R1-SQL-FETCH-2">
  <title>
   Usage
  </title>

  <para>
   The following example traverses a table using a cursor.

<programlisting>
-- Set up and use a cursor:

BEGIN WORK;
DECLARE liahona SCROLL CURSOR FOR SELECT * FROM films;

-- Fetch first 5 rows in the cursor liahona:
FETCH FORWARD 5 IN liahona;

<computeroutput>
 code  |          title          | did | date_prod  |  kind    | len
-------+-------------------------+-----+------------+----------+-------
 BL101 | The Third Man           | 101 | 1949-12-23 | Drama    | 01:44
 BL102 | The African Queen       | 101 | 1951-08-11 | Romantic | 01:43
 JL201 | Une Femme est une Femme | 102 | 1961-03-12 | Romantic | 01:25
 P_301 | Vertigo                 | 103 | 1958-11-14 | Action   | 02:08
 P_302 | Becket                  | 103 | 1964-02-03 | Drama    | 02:28
</computeroutput>

-- Fetch previous row:
FETCH PRIOR FROM liahona;

<computeroutput>
 code  | title   | did | date_prod  | kind   | len
-------+---------+-----+------------+--------+-------
 P_301 | Vertigo | 103 | 1958-11-14 | Action | 02:08
</computeroutput>

-- close the cursor and commit work:

CLOSE liahona;
COMMIT WORK;
</programlisting>
  </para>        
 </refsect1>

 <refsect1 id="R1-SQL-FETCH-3">
  <title>
   Compatibility
  </title>

  <refsect2 id="R2-SQL-FETCH-4">
   <refsect2info>
    <date>2003-03-11</date>
   </refsect2info>
   <title>
    SQL92
   </title>

   <para>
    <acronym>SQL92</acronym> defines <command>FETCH</command> for use
    in embedded contexts only.  Therefore, it describes placing the
    results into explicit variables using an <literal>INTO</> clause,
    for example:

    <synopsis>
FETCH ABSOLUTE <replaceable class="PARAMETER">n</replaceable>
    FROM <replaceable class="PARAMETER">cursor</replaceable>
    INTO :<replaceable class="PARAMETER">variable</replaceable> [, ...]
    </synopsis>

    <productname>PostgreSQL</productname>'s use of non-embedded
    cursors is non-standard, and so is its practice of returning the
    result data as if it were a <command>SELECT</command> result.
    Other than this point, <command>FETCH</command> is fully
    upward-compatible with <acronym>SQL92</acronym>.
   </para>

   <para>
    The <command>FETCH</command> forms involving FORWARD and BACKWARD
    (including the forms FETCH <replaceable
    class="PARAMETER">count</replaceable> and FETCH ALL, in which
    FORWARD is implicit) are <productname>PostgreSQL</productname>
    extensions.
   </para>

   <para>
    <acronym>SQL92</acronym> allows only <literal>FROM</> preceding the
    cursor name; the option to use <literal>IN</> is an extension.
   </para>
  </refsect2>
 </refsect1>
</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->