DECLARE
Defines a cursor.
Queries involving cursors declared by DECLARE can only be run on Hybrid DPS clusters, not on Extreme DPS clusters.
Syntax
DECLARE <name> [INSENSITIVE] [NO SCROLL] [PARALLEL RETRIEVE] CURSOR
[{WITH | WITHOUT} HOLD]
FOR <query>
Description
DECLARE allows a user to create a cursor, which can be used to retrieve a small number of rows at a time out of a larger query. Cursors can return data in text format using FETCH.
This page describes usage of cursors at the SQL command level.
Normal cursors return data in text format, the same as a SELECT would produce. Since data is stored natively in binary format, the system must do a conversion to produce the text format. Once the information comes back in text form, the client application may need to convert it to a binary format to manipulate it. In addition, data in the text format is often larger in size than in the binary format. Binary cursors return the data in a binary representation that may be more easily manipulated. Nevertheless, if you intend to display the data as text anyway, retrieving it in text form will save you some effort on the client side.
As an example, if a query returns a value of one from an integer column, you would get a string of 1 with a default cursor whereas with a binary cursor you would get a 4-byte field containing the internal representation of the value (in big-endian byte order).
Binary cursors should be used carefully. Many applications, including psql, are not prepared to handle binary cursors and expect data to come back in the text format.
When the client application uses the 'extended query' protocol to issue a FETCH command, the Bind protocol message specifies whether data is to be retrieved in text or binary format. This choice overrides the way that the cursor is defined. The concept of a binary cursor as such is thus obsolete when using extended query protocol — any cursor can be treated as either text or binary.
Parameters
-
<name>The name of the cursor.
-
INSENSITIVEIndicates that data retrieved from the cursor should be unaffected by updates to the tables underlying the cursor while the cursor exists. In Relyt, all cursors are insensitive. This key word currently has no effect and is present for compatibility with the SQL standard.
-
NO SCROLLA cursor cannot be used to retrieve rows in a nonsequential fashion. This is the default behavior in Relyt, since scrollable cursors (
SCROLL) are not supported. -
WITH HOLDorWITHOUT HOLDWITH HOLDspecifies that the cursor may continue to be used after the transaction that created it successfully commits.WITHOUT HOLDspecifies that the cursor cannot be used outside of the transaction that created it.WITHOUT HOLDis the default.noteRelyt does not support declaring a
PARALLEL RETRIEVEcursor with theWITH HOLDclause.WITH HOLDalso cannot not be specified when the query includes aFOR UPDATEorFOR SHAREclause. -
<query>A SELECT or VALUES command which will provide the rows to be returned by the cursor.
-
Cannot reference a view or external table.
-
References only one table.
The table must be updatable. For example, the following are not updatable: table functions, set-returning functions, append-only tables, columnar tables.
-
Cannot contain any of the following:
-
A grouping clause
-
A set operation such as
UNION ALLorUNION DISTINCT -
A sorting clause
-
A windowing clause
-
A join or a self-join
Specifying the
FOR UPDATEclause in theSELECTcommand prevents other sessions from changing the rows between the time they are fetched and the time they are updated. Without theFOR UPDATEclause, a subsequent use of theUPDATEorDELETEcommand with theWHERE CURRENT OFclause has no effect if the row was changed since the cursor was created. -
-
Specifying the FOR UPDATE clause in the SELECT command locks the entire table, not just the selected rows.
-
FOR READ ONLYSpecifies that the cursor is used in a read-only mode.
Examples
Declare a cursor:
DECLARE mycursor CURSOR FOR SELECT * FROM mytable;
Usage notes
Unless WITH HOLD is specified, the cursor created by this command can only be used within the current transaction. Thus, DECLARE without WITH HOLD is useless outside a transaction block: the cursor would survive only to the completion of the statement. Therefore Relyt reports an error if this command is used outside a transaction block. Use BEGIN and COMMIT (or ROLLBACK) to define a transaction block.
If WITH HOLD is specified and the transaction that created the cursor successfully commits, the cursor can continue to be accessed by subsequent transactions in the same session. (But if the creating transaction ends prematurely, the cursor is removed.) A cursor created with WITH HOLD is closed when an explicit CLOSE command is issued on it, or the session ends. In the current implementation, the rows represented by a held cursor are copied into a temporary file or memory area so that they remain available for subsequent transactions.
If you create a cursor with the DECLARE command in a transaction, you cannot use the SET command in the transaction until you close the cursor with the CLOSE command.
Scrollable cursors are not currently supported in Relyt. You can only use FETCH or RETRIEVE to move the cursor position forward, not backwards.
DECLARE ... FOR UPDATE is not supported with append-optimized tables.
SQL standard compatibility
SQL standard allows cursors only in embedded SQL and in modules. Relyt permits cursors to be used interactively.
Relyt does not implement an OPEN statement for cursors. A cursor is considered to be open when it is declared.
The SQL standard allows cursors to move both forward and backward. All Relyt cursors are forward moving only (not scrollable).
Binary cursors are a Relyt extension.