summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/ref/fetch.sgml
blob: f0f3ac2a02899b933fcc596db28eaaece76b51e7 (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
<!--
doc/src/sgml/ref/fetch.sgml
PostgreSQL documentation
-->

<refentry id="sql-fetch">

 <indexterm zone="sql-fetch">
  <primary>FETCH</primary>
 </indexterm>

 <indexterm zone="sql-fetch">
  <primary>cursor</primary>
  <secondary>FETCH</secondary>
 </indexterm>
 <refmeta>
  <refentrytitle>FETCH</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>FETCH</refname>
  <refpurpose>retrieve rows from a query using a cursor</refpurpose>
 </refnamediv>

 <refsynopsisdiv>
<!-- Note the "direction" bit is also in ref/move.sgml -->
<synopsis>
FETCH [ <replaceable class="parameter">direction</replaceable> ] [ FROM | IN ] <replaceable class="parameter">cursor_name</replaceable>

<phrase>where <replaceable class="parameter">direction</replaceable> can be one of:</phrase>

    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>
 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

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

  <para>
   A cursor has an associated position, which is used by
   <command>FETCH</command>.  The cursor position can be before the first row of the
   query result, 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</command> 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</command> or <command>FETCH BACKWARD
   ALL</command> will always leave the cursor positioned after the last row or before
   the first row.
  </para>

  <para>
   The forms <literal>NEXT</literal>, <literal>PRIOR</literal>, <literal>FIRST</literal>,
   <literal>LAST</literal>, <literal>ABSOLUTE</literal>, <literal>RELATIVE</literal> 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 <literal>FORWARD</literal> and <literal>BACKWARD</literal>
   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>

  <para>
   <literal>RELATIVE 0</literal>, <literal>FORWARD 0</literal>, and
   <literal>BACKWARD 0</literal> 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>

  <note>
   <para>
    This page describes usage of cursors at the SQL command level.
    If you are trying to use cursors inside a <application>PL/pgSQL</application>
    function, the rules are different &mdash;
    see <xref linkend="plpgsql-cursor-using"/>.
   </para>
  </note>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <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><literal>NEXT</literal></term>
        <listitem>
         <para>
          Fetch the next row. This is the default if <replaceable
          class="parameter">direction</replaceable> is omitted.
         </para>
        </listitem>
       </varlistentry>

       <varlistentry>
        <term><literal>PRIOR</literal></term>
        <listitem>
         <para>
          Fetch the prior row.
         </para>
        </listitem>
       </varlistentry>

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

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

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

       <varlistentry>
        <term><literal>RELATIVE <replaceable class="parameter">count</replaceable></literal></term>
        <listitem>
         <para>
          Fetch the <replaceable
          class="parameter">count</replaceable>'th succeeding row, or
          the <literal>abs(<replaceable
          class="parameter">count</replaceable>)</literal>'th prior
          row if <replaceable class="parameter">count</replaceable> is
          negative.  <literal>RELATIVE 0</literal> re-fetches the
          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
          <literal>FORWARD <replaceable
          class="parameter">count</replaceable></literal>).
         </para>
        </listitem>
       </varlistentry>

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

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

       <varlistentry>
        <term><literal>FORWARD <replaceable class="parameter">count</replaceable></literal></term>
        <listitem>
         <para>
          Fetch the next <replaceable
          class="parameter">count</replaceable> rows.
          <literal>FORWARD 0</literal> re-fetches the current row.
         </para>
        </listitem>
       </varlistentry>

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

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

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

       <varlistentry>
        <term><literal>BACKWARD ALL</literal></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 <literal>FORWARD</literal> and
      <literal>BACKWARD</literal> cases, specifying a negative <replaceable
      class="parameter">count</replaceable> is equivalent to changing
      the sense of <literal>FORWARD</literal> and <literal>BACKWARD</literal>.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">cursor_name</replaceable></term>
    <listitem>
     <para>
      An open cursor's name.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1>
  <title>Outputs</title>

  <para>
   On successful completion, a <command>FETCH</command> command returns a command
   tag of the form
<screen>
FETCH <replaceable class="parameter">count</replaceable>
</screen>
   The <replaceable class="parameter">count</replaceable> is the number
   of rows fetched (possibly zero).  Note that in
   <application>psql</application>, the command tag will not actually be
   displayed, since <application>psql</application> displays the fetched
   rows instead.
  </para>
 </refsect1>

 <refsect1>
  <title>Notes</title>

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

  <para>
   <literal>ABSOLUTE</literal> 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
   <literal>FETCH ABSOLUTE 0</literal>) is fast.
  </para>

  <para>
   <link linkend="sql-declare"><command>DECLARE</command></link>
   is used to define a cursor.  Use
   <link linkend="sql-move"><command>MOVE</command></link>
   to change cursor position without retrieving data.
  </para>
 </refsect1>

 <refsect1>
  <title>Examples</title>

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

<programlisting>
BEGIN WORK;

-- Set up a cursor:
DECLARE liahona SCROLL CURSOR FOR SELECT * FROM films;

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

 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

-- Fetch the previous row:
FETCH PRIOR FROM liahona;

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

-- Close the cursor and end the transaction:
CLOSE liahona;
COMMIT WORK;
</programlisting></para>
 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   The SQL standard defines <command>FETCH</command> for use in
   embedded SQL only.  The variant of <command>FETCH</command>
   described here returns the data as if it were a
   <command>SELECT</command> result rather than placing it in host
   variables.  Other than this point, <command>FETCH</command> is
   fully upward-compatible with the SQL standard.
  </para>

  <para>
   The <command>FETCH</command> forms involving
   <literal>FORWARD</literal> and <literal>BACKWARD</literal>, as well
   as the forms <literal>FETCH <replaceable
   class="parameter">count</replaceable></literal> and <literal>FETCH
   ALL</literal>, in which <literal>FORWARD</literal> is implicit, are
   <productname>PostgreSQL</productname> extensions.
  </para>

  <para>
   The SQL standard allows only <literal>FROM</literal> preceding the cursor
   name; the option to use <literal>IN</literal>, or to leave them out altogether, is
   an extension.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-close"/></member>
   <member><xref linkend="sql-declare"/></member>
   <member><xref linkend="sql-move"/></member>
  </simplelist>
 </refsect1>
</refentry>