DECLARE CURSOR statement [ESQL] [SP]

Description

Declares a cursor. Cursors are the primary means for manipulating the results of queries.

Syntax

DECLARE cursor-name
[   SCROLL
  | NO SCROLL 
  | DYNAMIC SCROLL 
]
CURSOR FOR
{ select-statement
| statement-name 
  [ FOR {READ ONLY | UPDATE [ OF column-name-list ] } ] 
| USING variable-name }

Parameters

cursor-name:

identifier

statement-name:

identifier | host-variable

column-name-list:

identifiers

variable-name:

identifier

Examples

Example 1

EXEC SQL DECLARE cur_employee SCROLL CURSOR 
FOR SELECT * FROM employee ;
EXEC SQL PREPARE employee_statement
FROM 'SELECT emp_lname FROM employee' ;
EXEC SQL DECLARE cur_employee CURSOR 
FOR employee_statement ;
BEGIN
  DECLARE cur_employee CURSOR FOR
      SELECT emp_lname
      FROM employee ;
  DECLARE name CHAR(40) ;
  OPEN cur_employee;
  LOOP
    FETCH NEXT cur_employee INTO name ;
    ...
  END LOOP
  CLOSE cur_employee;
END

Usage

The DECLARE CURSOR statement declares a cursor with the specified name for a SELECT statement or a CALL statement.

SCROLL A cursor declared as SCROLL supports the NEXT, PRIOR, FIRST, LAST, ABSOLUTE, and RELATIVE options of the FETCH statement. A SCROLL cursor allows you to fetch an arbitrary row in the result set while the cursor is open.

NO SCROLL A cursor declared as NO SCROLL is restricted to moving forward through the result set using only the FETCH NEXT and FETCH ABSOLUTE (0) seek operations.

Since rows cannot be returned to once the cursor leaves the row, there are no sensitivity restrictions on the cursor. Consequently, when a NO SCROLL cursor is requested, Sybase IQ supplies the most efficient kind of cursor, which is an asensitive cursor.

DYNAMIC SCROLL A cursor declared as DYNAMIC SCROLL supports the NEXT, PRIOR, FIRST, LAST, ABSOLUTE, and RELATIVE options of the FETCH statement. A DYNAMIC SCROLL cursor allows you to fetch an arbitrary row in the result set while the cursor is open.

FOR statement-name Statements are named using the PREPARE statement. Cursors can be declared only for a prepared SELECT or CALL.

FOR READ ONLY A cursor declared FOR READ ONLY may not be used in a positioned UPDATE or a positioned DELETE operation.

FOR UPDATE You can update the cursor result set of a cursor declared FOR UPDATE. Only asensitive behavior is supported for updatable cursors; any other sensitivity is ignored.

When the cursor is opened, exclusive table locks are taken on all tables that are opened for update. Stand-alone LOAD TABLE, UPDATE, INSERT, DELETE, and TRUNCATE statements are not allowed on tables that are opened for update in the same transaction, since Sybase IQ permits only one statement to modify a table at a time. You can open only one updatable cursor on a specific table at a time.

Updatable cursors are allowed to scroll, except over Open Client.

READ ONLY is the default value of the FOR clause.

OF column-name-list The list of columns from the cursor result set (specified by the select-statement) defined as updatable.

USING variable-name You can declare a cursor on a variable in stored procedures and user-defined functions. The variable is a string containing a SELECT statement for the cursor. The variable must be available when the DECLARE is processed, and so must be one of the following:


Embedded SQL

Statements are named using the PREPARE statement. Cursors can be declared only for a prepared SELECT or CALL.


Updatable cursor support

Sybase IQ support of updatable cursors is similar to Adaptive Server Anywhere support of updatable cursors. For a full discussion of cursor types and working with cursors, see the Adaptive Server Anywhere Programming Guide. This section contains information important to the use of updatable cursors in Sybase IQ.

Sybase IQ supports one type of cursor sensitivity, which is defined in terms of which changes to underlying data are visible. All Sybase IQ cursors are asensitive, which means that changes may be reflected in the membership, order, or values of the result set seen through the cursor, or may not be reflected at all.

With an asensitive cursor, changes effected by positioned UPDATE and positioned DELETE statements are visible in the cursor result set, except where client side caching prevents seeing these changes. Inserted rows are not visible.

Rows that are updated so that they no longer meet the requirements of the WHERE clause of the open cursor are still visible.

When using cursors there is always a trade-off between efficiency and consistency. Asensitive cursors provide efficient performance at the expense of consistency.

Sybase IQ supports updatable cursors on single tables.

Supported query specifications for updatable cursors in Sybase IQ are as follows:

Sybase IQ does not permit updatable cursors on queries that contain any operator that precludes a one-to-one mapping of result set rows to rows in a base table, specifically:

See the description of the UPDATE (positioned) statement [ESQL] [SP] for information on the columns and expressions allowed in the SET clause for the update of a row in the result set of a cursor.

Sybase IQ supports inserts only on updatable cursors where all nonnullable, nonidentity columns are both selected and updatable.

In Sybase IQ, COMMIT and ROLLBACK are not allowed inside an open updatable cursor, even if the cursor is opened as a hold cursor. IQ does support ROLLBACK TO SAVEPOINT inside an updatable cursor.

Any failure that occurs after the cursor is open results in a rollback of all operations that have been performed through this open cursor.


Updatable cursor limitations

A declared cursor is read-only and not updatable in cases where:

If IQ fails to set an updatable cursor when requested, see the .iqmsg file for an related information.


Updatable cursor differences

Sybase IQ updatable cursors differ from ANSI SQL/3 standard behavior as follows:


Side effects

None.

Standards

Permissions

None.

See also