The DECLARE CURSOR statement defines a cursor.
This statement can only be embedded in an application program. It is not an executable statement. It must not be specified in Java™.
No authorization is required to use this statement. However to use OPEN or FETCH for the cursor, the privileges held by the authorization ID of the statement must include at least one of the following:
The SELECT statement of the cursor is one of the following:
If statement-name is specified:
If the select-statement is specified:
For information on the system authorities corresponding to SQL privileges, see Corresponding System Authorities When Checking Privileges to a Table or View.
.-ASENSITIVE-------------. >>-DECLARE--cursor-name--+------------------------+-------------> +-INSENSITIVE------------+ | .-DYNAMIC-. | '-SENSITIVE--+---------+-' .-NO SCROLL-. >--+-----------+------------------------------------------------> '-SCROLL----' .-WITHOUT HOLD-. .-WITHOUT RETURN-------------. (1) >--CURSOR--+--------------+--+----------------------------+-------> '-WITH HOLD----' | .-TO CALLER-. | '-WITH RETURN--+-----------+-' '-TO CLIENT-' >--FOR--+-select-statement-+----------------------------------->< '-statement-name---'
When WITH HOLD is specified, a commit operation commits all the changes in the current unit of work, and releases all locks except those that are required to maintain the cursor position. Afterwards, a FETCH statement is required before a Positioned UPDATE or DELETE statement can be executed.
All cursors are implicitly closed by a CONNECT (Type 1) or rollback operation. All cursors associated with a connection are implicitly closed by a disconnect of the connection. A cursor is also implicitly closed by a commit operation if WITH HOLD is not specified, or if the connection associated with the cursor is in the release-pending state.
If a cursor is closed before the commit operation, the effect is the same as if the cursor was declared without the WITH HOLD option.
Within a procedure, cursors declared using the WITH RETURN clause that are still open when the SQL procedure ends define the result sets from the SQL procedure. All other open cursors in an SQL procedure are closed when the SQL procedure ends. Otherwise, any cursors open at the end of an external procedure are considered the result sets.
For non-scrollable cursors, the result set consists of all rows from the current cursor position to the end of the result table. For scrollable cursors, the result set consists of all rows of the result table.
TO CLIENT may be necessary if the result set is returned from an ILE program with multiple modules.
The select-statement must not include parameter markers (except for REXX), but can include references to variables. In host languages, other than REXX, the declarations of the host variables must precede the DECLARE CURSOR statement in the source program. In REXX, parameter markers must be used in place of variables and the statement must be prepared.
Placement of DECLARE CURSOR: The DECLARE CURSOR statement must precede all statements that explicitly reference the cursor by name, except in C and PL/I.
Result table of a cursor: A cursor in the open state designates a result table and a position relative to the rows of that table. The table is the result table specified by the SELECT statement of the cursor.
A cursor is deletable if all of the following are true:
A result column in the select list of the outer fullselect associated with a cursor is updatable if all of the following are true:
A cursor is read-only if it is not deletable and not updatable.
If ORDER BY is specified and FOR UPDATE OF is specified, the columns in the FOR UPDATE OF clause cannot be the same as any columns specified in the ORDER BY clause.
If the FOR UPDATE OF clause is omitted, only the columns in the SELECT clause of the subselect that can be updated can be changed.
Temporary results: Certain select-statements may be implemented as temporary result tables.
Scope of a cursor: The scope of cursor-name is the source program in which it is defined; that is, the program submitted to the precompiler. Thus, a cursor can only be referenced by statements that are precompiled with the cursor declaration. For example, a program called from another separately compiled program cannot use a cursor that was opened by the calling program.
The scope of cursor-name is also limited to the thread in which the program that contains the cursor is running. For example, if the same program is running in two separate threads in the same job, the second thread cannot use a cursor that was opened by the first thread.
A cursor can only be referred to in the same instance of the program in the program stack unless CLOSQLCSR(*ENDJOB), CLOSQLCSR(*ENDSQL), or CLOSQLCSR(*ENDACTGRP) is specified on the CRTSQLxxx commands.
Although the scope of a cursor is the program in which it is declared, each package created from the program includes a separate instance of the cursor and more than one cursor can exist at run time. For example, assume a program using CONNECT (Type 2) statements connects to location X and location Y in the following sequence:
EXEC SQL DECLARE C CURSOR FOR... EXEC SQL CONNECT TO X; EXEC SQL OPEN C; EXEC SQL FETCH C INTO... EXEC SQL CONNECT TO Y; EXEC SQL OPEN C; EXEC SQL FETCH C INTO...
The second OPEN C statement does not cause an error because it refers to a different instance of cursor C.
A SELECT statement is evaluated at the time the cursor is opened. If the same cursor is opened, closed, and then opened again, the results may be different. If the SELECT statement of a cursor contains CURRENT DATE, CURRENT TIME, or CURRENT TIMESTAMP, all references to these special registers will yield the same respective datetime value on each FETCH. The value is determined when the cursor is opened. Multiple cursors using the same SELECT statement can be opened concurrently. They are each considered independent activities.
Using sequence expressions: For information regarding using NEXT VALUE and PREVIOUS VALUE expressions with a cursor, see Using sequence expressions with a cursor.
Blocking of data: For more efficient processing of data, the database manager can block data for read-only cursors. If a cursor is not going to be used in a Positioned UPDATE or DELETE statement, it should be declared as FOR READ ONLY.
Usage in REXX: If variables are used on the DECLARE CURSOR statement within a REXX procedure, then the DECLARE CURSOR must be the object of a PREPARE and EXECUTE.
Cursor sensitivity: The ALWCPYDTA precompile option is ignored for DYNAMIC SCROLL cursors. If sensitivity to inserts, updates, and deletes must be maintained, a temporary copy of the data is never made unless a temporary result is required to implement the query.
Syntax alternatives: The following keywords are synonyms supported for compatibility to prior releases. These keywords are non-standard and should not be used:
Example 1: Declare C1 as the cursor of a query to retrieve data from the table DEPARTMENT. The query itself appears in the DECLARE CURSOR statement.
EXEC SQL DECLARE C1 CURSOR FOR SELECT DEPTNO, DEPTNAME, MGRNO FROM DEPARTMENT WHERE ADMRDEPT = 'A00';
Example 2: Declare C1 as the cursor of a query to retrieve data from the table DEPARTMENT. Assume that the data will be updated later with a searched update and should be locked when the query executes. The query itself appears in the DECLARE CURSOR statement.
EXEC SQL DECLARE C1 CURSOR FOR SELECT DEPTNO, DEPTNAME, MGRNO FROM DEPARTMENT WHERE ADMRDEPT = 'A00' FOR READ ONLY WITH RS USE AND KEEP EXCLUSIVE LOCKS;
Example 3: Declare C2 as the cursor for a statement named STMT2.
EXEC SQL DECLARE C2 CURSOR FOR STMT2;
Example 4: Declare C3 as the cursor for a query to be used in positioned updates of the table EMPLOYEE. Allow the completed updates to be committed from time to time without closing the cursor.
EXEC SQL DECLARE C3 CURSOR WITH HOLD FOR SELECT * FROM EMPLOYEE FOR UPDATE OF WORKDEPT, PHONENO, JOB, EDLEVEL, SALARY;
Instead of explicitly specifying the columns to be updated, an UPDATE clause could have been used without naming the columns. This would allow all the updatable columns of the table to be updated. Since this cursor is updatable, it can also be used to delete rows from the table.
Example 5: In a C program, use the cursor C1 to fetch the values for a given project (PROJNO) from the first four columns of the EMPPROJACT table a row at a time and put them into the following host variables: EMP(CHAR(6)), PRJ(CHAR(6)), ACT(SMALLINT) and TIM(DECIMAL(5,2)). Obtain the value of the project to search for from the host variable SEARCH_PRJ (CHAR(6)). Dynamically prepare the select-statement to allow the project to search by to be specified when the program is executed.
void main () { EXEC SQL BEGIN DECLARE SECTION; char EMP[7]; char PRJ[7]; char SEARCH_PRJ[7]; short ACT; double TIM; char SELECT_STMT[201]; EXEC SQL END DECLARE SECTION; EXEC SQL INCLUDE SQLCA; strcpy(SELECT_STMT, "SELECT EMPNO, PROJNO, ACTNO, EMPTIME \ FROM EMPPROJACT \ WHERE PROJNO = ?"); . . . EXEC SQL PREPARE SELECT_PRJ FROM :SELECT_STMT; EXEC SQL DECLARE C1 CURSOR FOR SELECT_PRJ; /* Obtain the value for SEARCH_PRJ from the user. */ . . . EXEC SQL OPEN C1 USING :SEARCH_PRJ; EXEC SQL FETCH C1 INTO :EMP, :PRJ, :ACT, :TIM; if (strcmp(SQLSTATE, "02000", 5) ) { data_not_found(); } else { while (strcmp(SQLSTATE, "00", 2) || strcmp(SQLSTATE, "01", 2) ) { EXEC SQL FETCH C1 INTO :EMP, :PRJ, :ACT, :TIM; } } EXEC SQL CLOSE C1; . . . }
Example 6: The DECLARE CURSOR statement associates the cursor name C1 with the results of the SELECT. C1 is an updatable, scrollable cursor.
EXEC SQL DECLARE C1 SENSITIVE SCROLL CURSOR FOR SELECT DEPTNO, DEPTNAME, MGRNO FROM TDEPT WHERE ADMRDEPT = 'A00';
Example 7: Declare a cursor in order to fetch values from four columns and assign the values to variables using the Serializable (RR) isolation level:
DECLARE CURSOR1 CURSOR FOR SELECT COL1, COL2, COL3, COL4 FROM TBLNAME WHERE COL1 = :varname WITH RR