Updated on 2024-08-20 GMT+08:00

FETCH

Description

FETCH retrieves rows using a previously created cursor.

A cursor has an associated position, which is used by FETCH. 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 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.
  • FETCH ALL or FETCH BACKWARD ALL will always leave the cursor positioned after the last row or before the first row.

Precautions

  • If the cursor is declared with NO SCROLL, backward fetches like FETCH BACKWARD are not allowed.
  • The forms NEXT, PRIOR, FIRST, LAST, ABSOLUTE, and 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 (backward fetch) or after the last row (forward fetch) as appropriate.
  • The forms using FORWARD and BACKWARD retrieve the indicated number of rows moving in the forward or backward direction, leaving the cursor positioned on the last-returned row or after (backward fetch)/before (forward fetch) all rows if the count exceeds the number of rows available.
  • 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 action will succeed unless the cursor is positioned before the first row or after the last row. If the cursor is positioned before the first row or after the last row, no row is returned.
  • If the cursor of FETCH involves a non-system catalog, backward fetches like BACKWARD, PRIOR, and FIRST are not allowed.

Syntax

FETCH [ direction { FROM | IN } ] cursor_name;

The direction clause specifies optional parameters.

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
NEXT
   | PRIOR
   | FIRST
   | LAST
   | ABSOLUTE count
   | RELATIVE count
   | count
   | ALL
   | FORWARD
   | FORWARD count
   | FORWARD ALL
   | BACKWARD
   | BACKWARD count
   | BACKWARD ALL

Parameters

  • direction

    Defines the fetch direction.

    Value range:

    • NEXT (default value)

      Fetches the next row.

    • PRIOR

      Fetches the prior row.

    • FIRST

      Fetches the first row of the query (same as ABSOLUTE 1).

    • LAST

      Fetches the last row of the query (same as ABSOLUTE -1).

    • ABSOLUTE count

      Fetches the count'th row of the query.

      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.

      Value range: a possibly-signed integer

      • If count is positive, the count'th row of the query will be fetched. If count is less than the current cursor position, rewind is required, which is currently not supported.
      • If count is negative or 0, backward scan is required, which is currently not supported.
    • RELATIVE count

      Fetches the count'th succeeding row or the count'th prior row if count is negative.

      Value range: a possibly-signed integer

      • If count is positive, the countth succeeding row will be fetched.
      • If count is negative or 0, backward scan is required, which is currently not supported.
      • If the current row contains no data, RELATIVE 0 returns null.
    • count

      Fetches the next count rows (same as FORWARD count).

    • ALL

      Fetches all remaining rows (same as FORWARD ALL).

    • FORWARD

      Fetches the next row (same as NEXT).

    • FORWARD count

      Fetches the next or prior count rows (same as RELATIVE count).

    • FORWARD ALL

      Fetches all remaining rows.

    • BACKWARD

      Fetches the prior row (same as PRIOR).

    • BACKWARD count

      Fetches the prior count rows (scanning backwards).

      Value range: a possibly-signed integer

      • If count is a positive integer, fetches the (count)'th prior row.
      • If count is a negative integer, fetches the abs(count)'th succeeding row.
      • BACKWARD 0 re-fetches the current row, if any.
    • BACKWARD ALL

      Fetches all prior rows (scanning backwards).

  • { FROM | IN } cursor_name

    Specifies the cursor name using the keyword FROM or IN.

    Value range: an existing cursor name

Examples

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
-- Create the test table and insert 20 data records into the table.
gaussdb=# CREATE TABLE test(c1 int, c2 int);
gaussdb=# INSERT INTO test VALUES (generate_series(1,20),generate_series(1,20));

-- Start a transaction and create a cursor named cursor1.
gaussdb=# START TRANSACTION;
gaussdb=# CURSOR cursor1 FOR SELECT * FROM test ORDER BY 1;

-- The cursor retrieves three rows of data from the associated position.
gaussdb=# FETCH FORWARD 3 FROM cursor1;
 c1 | c2 
----+----
  1 |  1
  2 |  2
  3 |  3
(3 rows)

-- Close the cursor and commit the transaction.
gaussdb=# CLOSE cursor1;
gaussdb=# END;

-- Delete the table.
gaussdb=# DROP TABLE test;

Helpful Links

CLOSE, MOVE, and CURSOR