FETCH SQL - Language Statements FETCH retrieve rows from a query using a cursor 2003-03-11 FETCH [ direction { FROM | IN } ] cursor where direction can be empty or one of: NEXT PRIOR FIRST LAST ABSOLUTE count RELATIVE count count ALL FORWARD FORWARD count FORWARD ALL BACKWARD BACKWARD count BACKWARD ALL 2003-03-11 Inputs direction direction defines the fetch direction and number of rows to fetch. It can be one of the following: NEXT fetch next row. This is the default if direction is omitted. PRIOR fetch prior row. FIRST fetch first row of query (same as ABSOLUTE 1). LAST fetch last row of query (same as ABSOLUTE -1). ABSOLUTE count fetch the count'th row of query, or the abs(count)'th row from the end if count < 0. Position before first row or after last row if count is out of range; in particular, ABSOLUTE 0 positions before first row. RELATIVE count fetch the count'th succeeding row, or the abs(count)'th prior row if count < 0. RELATIVE 0 re-fetches current row, if any. count fetch the next count rows (same as FORWARD count). ALL fetch all remaining rows (same as FORWARD ALL). FORWARD fetch next row (same as NEXT). FORWARD count fetch next count rows. FORWARD 0 re-fetches current row. FORWARD ALL fetch all remaining rows. BACKWARD fetch prior row (same as PRIOR). BACKWARD count fetch prior count rows (scanning backwards). BACKWARD 0 re-fetches current row. BACKWARD ALL fetch all prior rows (scanning backwards). count count is a possibly-signed integer constant, determining the location or number of rows to fetch. For FORWARD and BACKWARD cases, specifying a negative count is equivalent to changing the sense of FORWARD and BACKWARD. cursor An open cursor's name. 2003-03-11 Outputs FETCH returns rows from the result of the query defined by the specified cursor. The following messages will be returned if the query fails: WARNING: PerformPortalFetch: portal "cursor" not found There is no cursor with the specified name. 2003-03-11 Description FETCH retrieves rows using a cursor. A cursor has an associated position that is used by 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 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. 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. The forms using FORWARD and BACKWARD are not in the SQL standard, but are PostgreSQL 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 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 will succeed unless the cursor is positioned before the first row or after the last row; in which case, no row is returned. 2003-03-11 Notes The cursor should be declared with the SCROLL option if one intends to use any variants of FETCH other than FETCH NEXT or FETCH FORWARD with a positive count. For simple queries PostgreSQL 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. 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. Updating data via a cursor is not supported by PostgreSQL, 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 UPDATE commands to replace data. is used to define a cursor. Use to change cursor position without retrieving data. Usage The following example traverses a table using a cursor. -- 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; 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 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 commit work: CLOSE liahona; COMMIT WORK; Compatibility 2003-03-11 SQL92 SQL92 defines FETCH for use in embedded contexts only. Therefore, it describes placing the results into explicit variables using an INTO clause, for example: FETCH ABSOLUTE n FROM cursor INTO :variable [, ...] PostgreSQL's use of non-embedded cursors is non-standard, and so is its practice of returning the result data as if it were a SELECT result. Other than this point, FETCH is fully upward-compatible with SQL92. The FETCH forms involving FORWARD and BACKWARD (including the forms FETCH count and FETCH ALL, in which FORWARD is implicit) are PostgreSQL extensions. SQL92 allows only FROM preceding the cursor name; the option to use IN is an extension.