<?xml version="1.0" encoding="utf-8"?> <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"> <html xmlns="http://www.w3.org/1999/xhtml" lang="en-US" xml:lang="en-us"> <head> <meta http-equiv="Content-Type" content="text/html; charset=utf-8" /> <meta name="dc.language" scheme="rfc1766" content="en-us" /> <!-- All rights reserved. Licensed Materials Property of IBM --> <!-- US Government Users Restricted Rights --> <!-- Use, duplication or disclosure restricted by --> <!-- GSA ADP Schedule Contract with IBM Corp. --> <meta name="dc.date" scheme="iso8601" content="2005-09-19" /> <meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" /> <meta name="security" content="public" /> <meta name="Robots" content="index,follow"/> <meta http-equiv="PICS-Label" content='(PICS-1.1 "http://www.icra.org/ratingsv02.html" l gen true r (cz 1 lz 1 nz 1 oz 1 vz 1) "http://www.rsac.org/ratingsv01.html" l gen true r (n 0 s 0 v 0 l 0) "http://www.classify.org/safesurf/" l gen true r (SS~~000 1))' /> <meta name="keywords" content="DECLARE CURSOR statement, DECLARE CURSOR, SQL statements, defining, cursor, in DECLARE CURSOR statement, cursor-name, ASENSITIVE clause, SENSITIVE clause, INSENSITIVE clause, NO SCROLL clause, SCROLL clause, WITH NO HOLD clause, WITH HOLD clause, HOLD clause, WITHOUT RETURN clause, WITH RETURN clause, select-statement, statement-name, deletable, updatable, read-only, result table, temporary, in FETCH statement, RELATIVE clause" /> <title>DECLARE CURSOR</title> <link rel="stylesheet" type="text/css" href="ibmidwb.css" /> <link rel="stylesheet" type="text/css" href="ic.css" /> </head> <body> <a id="Top_Of_Page" name="Top_Of_Page"></a><!-- Java sync-link --> <script language = "Javascript" src = "../rzahg/synch.js" type="text/javascript"></script> <a name="h2dclcu"></a> <h2 id="h2dclcu"><a href="rbafzmst02.htm#ToC_970">DECLARE CURSOR</a></h2><a id="idx2202" name="idx2202"></a><a id="idx2203" name="idx2203"></a><a id="idx2204" name="idx2204"></a><a id="idx2205" name="idx2205"></a> <a name="dclcu"></a> <p id="dclcu">The DECLARE CURSOR statement defines a cursor.</p> <a name="wq1383"></a> <h3 id="wq1383"><a href="rbafzmst02.htm#ToC_971">Invocation</a></h3> <p>This statement can only be embedded in an application program. It is not an executable statement. It must not be specified in Java™.</p> <a name="wq1384"></a> <h3 id="wq1384"><a href="rbafzmst02.htm#ToC_972">Authorization</a></h3> <p>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: </p> <ul> <li>For each table or view identified in the SELECT statement of the cursor: <ul> <li>The SELECT privilege on the table or view, and</li> <li>The system authority *EXECUTE on the library containing the table or view</li></ul></li> <li>Administrative authority</li></ul> <p>The SELECT statement of the cursor is one of the following: </p> <ul> <li>The prepared select-statement identified by the <var class="pv">statement-name</var>.</li> <li>The specified <var class="pv">select-statement</var>.</li></ul> <p>If <span class="bold-italic">statement-name</span> is specified: </p> <ul> <li>The authorization ID of the statement is the run-time authorization ID unless DYNUSRPRF(*OWNER) was specified on the CRTSQLxxx command when the program was created. For more information, see <a href="rbafzmstch2auth.htm#ch2auth">Authorization IDs and authorization names</a>.</li> <li>The authorization check is performed when the <var class="pv">select-statement</var> is prepared unless DLYPRP(*YES) is specified on the CRTSQLxxx command.</li> <li>The authorization check is performed when the cursor is opened for programs compiled with the DLYPRP(*YES) parameter.</li></ul> <p>If the <span class="bold-italic">select-statement</span> is specified: </p> <ul> <li>If USRPRF(*OWNER) or USRPRF(*NAMING) with SQL naming was specified on the CRTSQLxxx command, the authorization ID of the statement is the owner of the SQL program or package.</li> <li>If USRPRF(*USER) or USRPRF(*NAMING) with system naming was specified on the CRTSQLxxx command, the authorization ID of the statement is the run-time authorization ID.</li> <li>In REXX, the authorization ID of the statement is the run-time authorization ID.</li> <li>The authorization check is performed when the cursor is opened.</li></ul> <p>For information on the system authorities corresponding to SQL privileges, see <a href="rbafzmstgnt.htm#eqtablet">Corresponding System Authorities When Checking Privileges to a Table or View</a>.</p> <a name="wq1385"></a> <h3 id="wq1385"><a href="rbafzmst02.htm#ToC_973">Syntax</a></h3> <a href="rbafzmsth2clcu.htm#deccur"><img src="c.gif" alt="Click to skip syntax diagram" /></a> <pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn315.htm" border="0" /></span><a href="#skipsyn-314"><img src="c.gif" alt="Skip visual syntax diagram" border="0" /></a> .-ASENSITIVE-------------. >>-DECLARE--<span class="italic">cursor-name</span>--+------------------------+-------------> +-INSENSITIVE------------+ | .-DYNAMIC-. | '-SENSITIVE--+---------+-' .-NO SCROLL-. >--+-----------+------------------------------------------------> '-SCROLL----' .-WITHOUT HOLD-. .-WITHOUT RETURN-------------. (1) >--CURSOR--+--------------+--+----------------------------+-------> '-WITH HOLD----' | .-TO CALLER-. | '-WITH RETURN--+-----------+-' '-TO CLIENT-' >--FOR--+-<span class="italic">select-statement</span>-+----------------------------------->< '-<span class="italic">statement-name</span>---' </pre> <a name="skipsyn-314" id="skipsyn-314"></a> <a name="wq1386"></a> <div class="notelisttitle" id="wq1386">Notes:</div> <ol type="1"> <li>The HOLD and RETURN clauses can be specified in any order.</li> </ol> <a name="deccur"></a> <h3 id="deccur"><a href="rbafzmst02.htm#ToC_974">Description</a></h3> <dl class="parml"> <dt class="bold"><var class="pv">cursor-name</var> </dt><a id="idx2206" name="idx2206"></a> <dd>Names a cursor. The name must not be the same as the name of another cursor declared in your source program. </dd> <dt class="bold">ASENSITIVE, SENSITIVE, <span class="base">or</span> INSENSITIVE</dt> <dd>Specifies whether the cursor is asensitive, sensitive, or insensitive to changes. <dl class="parml"> <dt class="bold">ASENSITIVE</dt><a id="idx2207" name="idx2207"></a> <dd>Specifies that the cursor may behave as SENSITIVE or INSENSITIVE depending on how the <var class="pv">select-statement</var> is optimized. This is the default. </dd> <dt class="bold">SENSITIVE</dt><a id="idx2208" name="idx2208"></a> <dd>Specifies that changes made to the database after the cursor is opened are visible in the result table. The cursor has some level of sensitivity to any updates or deletes made to the rows underlying its result table after the cursor is opened. The cursor is always sensitive to positioned updates or deletes using the same cursor. Additionally, the cursor can have sensitivity to changes made outside this cursor. If the database manager cannot make changes visible to the cursor, then an error is returned. The database manager cannot make changes visible to the cursor when the cursor implicitly becomes read-only. (See <a href="rbafzmsth2clcu.htm#readonly2">Result table of a cursor</a>.) </dd> <dt class="bold">INSENSITIVE</dt><a id="idx2209" name="idx2209"></a> <dd>Specifies that once the cursor is opened, it does not have sensitivity to inserts, updates, or deletes performed by this or any other activation group. If INSENSITIVE is specified, the cursor is read-only and a temporary result is created when the cursor is opened. In addition, the SELECT statement cannot contain a FOR UPDATE clause and the application must allow a copy of the data (ALWCPYDTA(*OPTIMIZE) or ALWCPYDTA(*YES)). </dd> </dl> </dd> <dt class="bold">NO SCROLL <span class="base">or</span> SCROLL</dt> <dd>Specifies whether the cursor is scrollable or not scrollable. <dl class="parml"> <dt class="bold">NO SCROLL </dt><a id="idx2210" name="idx2210"></a> <dd>Specifies that the cursor is not scrollable. </dd> <dt class="bold">SCROLL </dt><a id="idx2211" name="idx2211"></a> <dd>Specifies that the cursor is scrollable. The cursor may or may not have immediate sensitivity to inserts, updates, and deletes done by other activation groups. </dd> </dl> </dd> <dt class="bold">WITHOUT HOLD <span class="base">or</span> WITH HOLD</dt> <dd>Specifies whether the cursor should be prevented from being closed as a consequence of a commit operation. <dl class="parml"> <dt class="bold">WITHOUT HOLD</dt><a id="idx2212" name="idx2212"></a> <dd>Does not prevent the cursor from being closed as a consequence of a commit operation. This is the default. </dd> <dt class="bold">WITH HOLD </dt><a id="idx2213" name="idx2213"></a><a id="idx2214" name="idx2214"></a><a id="idx2215" name="idx2215"></a> <dd>Prevents the cursor from being closed as a consequence of a commit operation. A cursor declared using the WITH HOLD clause is implicitly closed at commit time only if the connection associated with the cursor is ended during the commit operation. <p>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.</p> <p>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.</p> <p>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.</p> </dd> </dl> </dd> <dt class="bold">WITHOUT RETURN <span class="base">or</span> WITH RETURN</dt> <dd>Specifies whether the result table of the cursor is intended to be used as a result set that will be returned from a procedure. <dl class="parml"> <dt class="bold">WITHOUT RETURN </dt><a id="idx2216" name="idx2216"></a> <dd>Specifies that the result table of the cursor is not intended to be used as a result set that will be returned from a procedure. </dd> <dt class="bold"><a id="withreturn" name="withreturn"></a>WITH RETURN </dt><a id="idx2217" name="idx2217"></a> <dd>Specifies that the result table of the cursor is intended to be used as a result set that will be returned from a procedure. WITH RETURN is relevant only if the DECLARE CURSOR statement is contained within the source code for a procedure. In other cases, the precompiler may accept the clause, but it has no effect. <p>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.</p> <p>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.</p> <dl class="parml"> <dt class="bold">TO CALLER</dt> <dd>Specifies that the cursor can return a result set to the caller of the procedure. For example, if the caller is a client application, the result set is returned to the client application. </dd> <dt class="bold">TO CLIENT</dt> <dd>Specifies that the cursor can return a result set to the client application. This cursor is invisible to any intermediate nested procedures. If a function called the procedure either directly or indirectly, result sets cannot be returned to the client and the cursor will be closed after the procedure finishes. <p>TO CLIENT may be necessary if the result set is returned from an ILE program with multiple modules.</p> </dd> </dl> </dd> </dl> </dd> <dt class="bold"><var class="pv">select-statement</var> </dt><a id="idx2218" name="idx2218"></a> <dd>Specifies the SELECT statement of the cursor. See <a href="rbafzmstintsel.htm#intsel">select-statement</a> for more information. <p>The <var class="pv">select-statement</var> 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.</p> </dd> <dt class="bold"><var class="pv">statement-name</var></dt><a id="idx2219" name="idx2219"></a> <dd>The SELECT statement of the cursor is the prepared select-statement identified by the <var class="pv">statement-name</var> when the cursor is opened. The <var class="pv">statement-name</var> must not be identical to a <var class="pv">statement-name</var> specified in another DECLARE CURSOR statement of the source program. See <a href="rbafzmstpreph2.htm#preph2">PREPARE</a> for an explanation of prepared statements. </dd> </dl> <a name="wq1388"></a> <h3 id="wq1388"><a href="rbafzmst02.htm#ToC_975">Notes</a></h3> <p><span class="bold">Placement of DECLARE CURSOR:</span> The DECLARE CURSOR statement must precede all statements that explicitly reference the cursor by name, except in C and PL/I.</p> <a name="readonly2"></a> <p id="readonly2"><span class="bold">Result table of a cursor:</span> A cursor in the open state designates a <span class="italic">result table</span> and a position relative to the rows of that table. The table is the result table specified by the SELECT statement of the cursor.</p> <p>A cursor is <span class="italic">deletable</span> if all of the following are true:<a id="idx2220" name="idx2220"></a></p> <ul> <li>The outer fullselect identifies only one base table or deletable view.</li> <li>The outer fullselect does not include a GROUP BY clause or HAVING clause.</li> <li>The outer fullselect does not include aggregate functions in the select list.</li> <li>The outer fullselect does not include a UNION, UNION ALL, EXCEPT, or INTERSECT operator.</li> <li>The outer fullselect does not include the DISTINCT clause.</li> <li>The <var class="pv">select-statement</var> does not contain an ORDER BY clause, or the SENSITIVE keyword or FOR UPDATE clause is also specified.</li> <li>The <var class="pv">select-statement</var> does not include a FOR READ ONLY clause.</li> <li>The <var class="pv">select-statement</var> does not include a FETCH FIRST n ROWS ONLY clause.</li> <li>The result of the outer fullselect does not make use of a temporary table.</li> <li>The <var class="pv">select-statement</var> does not include the SCROLL keyword, or the SENSITIVE keyword or FOR UPDATE clause is also specified.</li> <li>The select list does not includes a DATALINK column unless a FOR UPDATE clause is specified.</li></ul> <p>A result column in the select list of the outer fullselect associated with a cursor is <span class="italic">updatable</span> if all of the following are true: <a id="idx2221" name="idx2221"></a></p> <ul> <li>The cursor is updatable.</li> <li>The result column is derived solely from a column of a table or an updatable column of a view. That is, at least one result column must not be derived from an expression that contains an operator, scalar function, constant, or a column that itself is derived from such expressions.</li></ul><a id="idx2222" name="idx2222"></a> <p>A cursor is <span class="italic">read-only</span> if it is not deletable and not updatable.</p> <p>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.</p> <p>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.</p> <p><span class="bold">Temporary results:</span> Certain <span class="italic">select-statements</span> may be implemented as temporary result tables.<a id="idx2223" name="idx2223"></a><a id="idx2224" name="idx2224"></a><a id="idx2225" name="idx2225"></a></p> <ul> <li> A temporary result table is created when: <ul> <li>INSENSITIVE is specified</li> <li>The ORDER BY and GROUP BY clauses specify different columns or columns in a different order.</li> <li>The ORDER BY and GROUP BY clauses include a user-defined function or one of the following scalar functions: DLVALUE, DLURLPATH, DLURLPATHONLY, DLURLSERVER, DLURLSCHEME, or DLURLCOMPLETE for DataLinks with an attribute of FILE LINK CONTROL and READ PERMISSION DB.</li> <li>The UNION, EXCEPT, INTERSECT, or DISTINCT clauses are specified.</li> <li>The ORDER BY or GROUP BY clauses specify columns which are not all from the same table.</li> <li>A logical file defined by the JOINDFT data definition specifications (DDS) keyword is joined to another file.</li> <li>A logical file that is based on multiple database file members is specified.</li> <li>The CURRENT or RELATIVE scroll options are specified on the FETCH statement when the select statement of the DECLARE CURSOR contains a GROUP BY clause.</li> <li>The FETCH FIRST n ROWS ONLY clause is specified.</li></ul></li> <li>Queries that include a subquery where: <ul> <li>The outermost query does not provide correlated values to any inner subselects.</li> <li>No IN, = ANY, = SOME, or <> ALL subqueries are referenced by the outermost query.</li></ul></li></ul> <p><span class="bold">Scope of a cursor:</span> The scope of <var class="pv">cursor-name</var> 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.</p> <p>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.</p> <p>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. </p> <ul> <li>If CLOSQLCSR(*ENDJOB) is specified, the cursor can be referred to by any instance of the program on the program stack.</li> <li>If CLOSQLCSR(*ENDSQL) is specified, the cursor can be referred to by any instance of the program on the program stack until the last SQL program on the program stack ends.</li> <li>If CLOSQLCSR(*ENDACTGRP) is specified, the cursor can be referred to by all instances of the module in the activation group until the activation group ends.</li></ul> <p>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: </p> <pre class="xmp">EXEC SQL <span class="bold">DECLARE</span> C <span class="bold">CURSOR FOR</span>... EXEC SQL <span class="bold">CONNECT TO</span> X; EXEC SQL <span class="bold">OPEN</span> C; EXEC SQL <span class="bold">FETCH</span> C <span class="bold">INTO</span>... EXEC SQL <span class="bold">CONNECT TO</span> Y; EXEC SQL <span class="bold">OPEN</span> C; EXEC SQL <span class="bold">FETCH</span> C <span class="bold">INTO</span>...</pre> <p>The second OPEN C statement does not cause an error because it refers to a different instance of cursor C.</p> <p>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.</p> <p><span class="bold">Using sequence expressions:</span> For information regarding using NEXT VALUE and PREVIOUS VALUE expressions with a cursor, see <a href="rbafzmstdatetimearith.htm#seqrefcsr">Using sequence expressions with a cursor</a>.</p> <p><span class="bold">Blocking of data:</span> 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.</p> <p><span class="bold">Usage in REXX:</span> 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.</p> <p><span class="bold">Cursor sensitivity:</span> 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.</p> <p><span class="bold">Syntax alternatives:</span> The following keywords are synonyms supported for compatibility to prior releases. These keywords are non-standard and should not be used:</p> <ul> <li>DYNAMIC SCROLL is a synonym for SENSITIVE DYNAMIC SCROLL</li></ul> <a name="wq1389"></a> <h3 id="wq1389"><a href="rbafzmst02.htm#ToC_976">Examples</a></h3> <p><span class="italic">Example 1:</span> Declare C1 as the cursor of a query to retrieve data from the table DEPARTMENT. The query itself appears in the DECLARE CURSOR statement. </p> <pre class="xmp"> EXEC SQL <span class="bold">DECLARE</span> C1 <span class="bold">CURSOR FOR SELECT</span> DEPTNO, DEPTNAME, MGRNO <span class="bold">FROM</span> DEPARTMENT <span class="bold">WHERE</span> ADMRDEPT = 'A00';</pre> <p><span class="italic">Example 2:</span> 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. </p> <pre class="xmp"> EXEC SQL <span class="bold">DECLARE</span> C1 <span class="bold">CURSOR FOR SELECT</span> DEPTNO, DEPTNAME, MGRNO <span class="bold">FROM</span> DEPARTMENT <span class="bold">WHERE</span> ADMRDEPT = 'A00' <span class="bold">FOR READ ONLY WITH RS USE AND KEEP EXCLUSIVE LOCKS</span>;</pre> <p><span class="italic">Example 3:</span> Declare C2 as the cursor for a statement named STMT2. </p> <pre class="xmp"> EXEC SQL <span class="bold">DECLARE</span> C2 <span class="bold">CURSOR FOR</span> STMT2;</pre> <p><span class="italic">Example 4:</span> 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. </p> <pre class="xmp"> EXEC SQL <span class="bold">DECLARE</span> C3 <span class="bold">CURSOR WITH HOLD FOR SELECT * FROM</span> EMPLOYEE <span class="bold">FOR UPDATE OF</span> WORKDEPT, PHONENO, JOB, EDLEVEL, SALARY;</pre> <p>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.</p> <p><span class="italic">Example 5:</span> 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 <var class="pv">select-statement</var> to allow the project to search by to be specified when the program is executed. </p> <pre class="xmp">void main () { EXEC SQL <span class="bold">BEGIN DECLARE SECTION</span>; char EMP[7]; char PRJ[7]; char SEARCH_PRJ[7]; short ACT; double TIM; char SELECT_STMT[201]; EXEC SQL <span class="bold">END DECLARE SECTION</span>; EXEC SQL <span class="bold">INCLUDE SQLCA</span>; strcpy(SELECT_STMT, "SELECT EMPNO, PROJNO, ACTNO, EMPTIME \ FROM EMPPROJACT \ WHERE PROJNO = ?"); . . . EXEC SQL <span class="bold">PREPARE</span> SELECT_PRJ <span class="bold">FROM</span> :SELECT_STMT; EXEC SQL <span class="bold">DECLARE</span> C1 <span class="bold">CURSOR FOR</span> SELECT_PRJ; /* Obtain the value for SEARCH_PRJ from the user. */ . . . EXEC SQL <span class="bold">OPEN</span> C1 <span class="bold">USING</span> :SEARCH_PRJ; EXEC SQL <span class="bold">FETCH</span> C1 <span class="bold">INTO</span> :EMP, :PRJ, :ACT, :TIM; if (strcmp(SQLSTATE, "02000", 5) ) { data_not_found(); } else { while (strcmp(SQLSTATE, "00", 2) || strcmp(SQLSTATE, "01", 2) ) { EXEC SQL <span class="bold">FETCH</span> C1 <span class="bold">INTO</span> :EMP, :PRJ, :ACT, :TIM; } } EXEC SQL <span class="bold">CLOSE</span> C1; . . . }</pre> <p><span class="italic">Example 6:</span> The DECLARE CURSOR statement associates the cursor name C1 with the results of the SELECT. C1 is an updatable, scrollable cursor. </p> <pre class="xmp"> EXEC SQL <span class="bold">DECLARE</span> C1 <span class="bold">SENSITIVE SCROLL CURSOR FOR</span> <span class="bold">SELECT</span> DEPTNO, DEPTNAME, MGRNO <span class="bold">FROM</span> TDEPT <span class="bold">WHERE</span> ADMRDEPT = 'A00';</pre> <p><span class="italic">Example 7:</span> Declare a cursor in order to fetch values from four columns and assign the values to variables using the Serializable (RR) isolation level: </p> <pre class="xmp"> <span class="bold">DECLARE</span> CURSOR1 <span class="bold">CURSOR FOR</span> <span class="bold">SELECT</span> COL1, COL2, COL3, COL4 <span class="bold">FROM</span> TBLNAME <span class="bold">WHERE</span> COL1 = :varname <span class="bold">WITH RR</span></pre> <p><a id="idx2226" name="idx2226"></a><a id="idx2227" name="idx2227"></a></p> <hr /><br /> [ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzdeallocatedescr.htm">Previous Page</a> | <a href="rbafzmstdgtt.htm">Next Page</a> | <a href="rbafzmst02.htm#wq1">Contents</a> | <a href="rbafzmstindex.htm#index">Index</a> ] <a id="Bot_Of_Page" name="Bot_Of_Page"></a> </body> </html>