294 lines
18 KiB
HTML
294 lines
18 KiB
HTML
<?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="OPEN statement, OPEN, SQL statements, preparing,
|
|
cursor, active set, in OPEN statement, cursor-name, USING clause, variable,
|
|
SQL-descriptor-name, USING DESCRIPTOR clause, descriptor-name, parameter marker,
|
|
closes cursor, error, closed state, closed state of cursor, closes cursors,
|
|
ending, unit of work, temporary tables in OPEN, temporary, table, replacement" />
|
|
<title>OPEN</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="hopen"></a>
|
|
<h2 id="hopen"><a href="rbafzmst02.htm#ToC_1177">OPEN</a></h2><a id="idx2926" name="idx2926"></a><a id="idx2927" name="idx2927"></a><a id="idx2928" name="idx2928"></a><a id="idx2929" name="idx2929"></a>
|
|
<a name="open"></a>
|
|
<p id="open">The OPEN statement opens a cursor.</p>
|
|
<a name="wq1642"></a>
|
|
<h3 id="wq1642"><a href="rbafzmst02.htm#ToC_1178">Invocation</a></h3>
|
|
<p>This statement can only be embedded in an application program. It is an
|
|
executable statement that cannot be dynamically prepared. It must not be specified
|
|
in Java™.</p>
|
|
<a name="wq1643"></a>
|
|
<h3 id="wq1643"><a href="rbafzmst02.htm#ToC_1179">Authorization</a></h3>
|
|
<p>See <a href="rbafzmsth2clcu.htm#h2dclcu">DECLARE CURSOR</a> for the authorization required to use a cursor.</p>
|
|
<a name="wq1644"></a>
|
|
<h3 id="wq1644"><a href="rbafzmst02.htm#ToC_1180">Syntax</a></h3>
|
|
<a href="rbafzmsthopen.htm#synsopen"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn360.htm"
|
|
border="0" /></span><a href="#skipsyn-359"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a>>>-OPEN--<span class="italic">cursor-name</span>-------------------------------------------->
|
|
|
|
>--+---------------------------------------------------------+-><
|
|
| .-,--------. |
|
|
| V | |
|
|
+-USING----<span><span class="italic">variable</span></span>-+-------------------------------------+
|
|
| .-LOCAL--. |
|
|
+-USING--<span>SQL</span>--DESCRIPTOR--+--------+--<span class="italic">SQL-descriptor-name</span>-+
|
|
| '-GLOBAL-' |
|
|
'-USING DESCRIPTOR--<span class="italic">descriptor-name</span>-----------------------'
|
|
|
|
</pre>
|
|
<a name="skipsyn-359" id="skipsyn-359"></a>
|
|
<a name="synsopen"></a>
|
|
<h3 id="synsopen"><a href="rbafzmst02.htm#ToC_1181">Description</a></h3>
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">cursor-name</var> </dt><a id="idx2930" name="idx2930"></a>
|
|
<dd>Identifies the cursor to be opened. The <var class="pv">cursor-name</var> must identify
|
|
a declared cursor as explained in the Notes for the DECLARE CURSOR statement.
|
|
When the OPEN statement is executed, the cursor must be in the closed state.
|
|
<p>The SELECT statement associated with the cursor is either: </p>
|
|
<ul>
|
|
<li>The <var class="pv">select-statement</var> specified in the DECLARE CURSOR statement,
|
|
or</li>
|
|
<li>The prepared <var class="pv">select-statement</var> identified by the <var class="pv">statement-name</var> specified in the DECLARE CURSOR statement. If the statement has not
|
|
been successfully prepared, or is not a <var class="pv">select-statement</var>, the cursor
|
|
cannot be successfully opened.</li></ul><p class="indatacontent">The result table of the cursor is derived by evaluating the SELECT statement.
|
|
The evaluation uses the current values of any special registers specified
|
|
in the SELECT statement and the current values of any variables specified
|
|
in the SELECT statement or the USING clause of the OPEN statement. The rows
|
|
of the result table can be derived during the execution of the OPEN statement
|
|
and a temporary table can be created to hold them; or they can be derived
|
|
during the execution of subsequent FETCH statements. In either case, the cursor
|
|
is placed in the open state and positioned before the first row of its result
|
|
table. If the table is empty the position of the cursor is effectively "after
|
|
the last row."</p>
|
|
</dd>
|
|
<dt class="bold">USING</dt><a id="idx2931" name="idx2931"></a>
|
|
<dd>Introduces a list of variables whose values are substituted for the
|
|
parameter markers (question marks) of a prepared statement. For an explanation
|
|
of parameter markers, see <a href="rbafzmstpreph2.htm#preph2">PREPARE</a>. If the DECLARE CURSOR statement
|
|
names a prepared statement that includes parameter markers, you must use USING.
|
|
If the prepared statement does not include parameter markers, USING is ignored.
|
|
<dl class="parml">
|
|
<dt class="bold">USING <var class="pv">variable,...</var> </dt><a id="idx2932" name="idx2932"></a>
|
|
<dd>Identifies host structures or variables that must be declared in the
|
|
program in accordance with the rules for declaring host structures and variables.
|
|
A reference to a host structure is replaced by a reference to each of its
|
|
variables. The number of variables must be the same as the number of parameter
|
|
markers in the prepared statement. The <span class="italic">n</span>th variable
|
|
corresponds to the <span class="italic">n</span>th parameter marker in the prepared
|
|
statement.
|
|
</dd>
|
|
<dt class="bold">USING SQL DESCRIPTOR <var class="pv">SQL-descriptor-name</var></dt>
|
|
<dd>Identifies an SQL descriptor.
|
|
<dl class="parml">
|
|
<dt class="bold">LOCAL</dt>
|
|
<dd>Specifies the scope of the name of the descriptor to be local to program
|
|
invocation.
|
|
</dd>
|
|
<dt class="bold">GLOBAL</dt>
|
|
<dd>Specifies the scope of the name of the descriptor to be global to the
|
|
SQL session.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">SQL-descriptor-name</var></dt>
|
|
<dd>Names the SQL descriptor. The name must identify a descriptor that already
|
|
exists with the specified scope. <a id="idx2933" name="idx2933"></a>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">USING DESCRIPTOR <var class="pv">descriptor-name</var> </dt><a id="idx2934" name="idx2934"></a><a id="idx2935" name="idx2935"></a><a id="idx2936" name="idx2936"></a>
|
|
<dd>Identifies an SQLDA that must contain a valid description of input variables.
|
|
<p>Before the OPEN statement is processed, the user must set the following fields
|
|
in the SQLDA. (The rules for REXX are different. For more information see
|
|
the <a href="../rzajp/rzajpkickoff.htm">Embedded SQL Programming</a> book.) </p>
|
|
<ul>
|
|
<li>SQLN to indicate the number of SQLVAR occurrences provided in the SQLDA</li>
|
|
<li>SQLDABC to indicate the number of bytes of storage allocated for the SQLDA</li>
|
|
<li>SQLD to indicate the number of variables used in the SQLDA when processing
|
|
the statement</li>
|
|
<li>SQLVAR occurrences to indicate the attributes of the variables</li></ul>
|
|
<p>The SQLDA must have enough storage to contain all SQLVAR occurrences.
|
|
If LOBs or distinct types are present in the results, there must be additional
|
|
SQLVAR entries for each parameter. For more information about the SQLDA, which
|
|
includes a description of the SQLVAR and an explanation on how to determine
|
|
the number of SQLVAR occurrences, see <a href="rbafzmstsqldda.htm#sqldda">Appendix D. SQLDA (SQL descriptor area)</a>.</p>
|
|
<p>SQLD must
|
|
be set to a value greater than or equal to zero and less than or equal to
|
|
SQLN. It must be the same as the number of parameter markers in the prepared
|
|
statement. The <span class="italic">n</span>th variable described by the SQLDA
|
|
corresponds to the <span class="italic">n</span>th parameter marker in the prepared
|
|
statement.</p>
|
|
</dd>
|
|
</dl>
|
|
<p>Note that because RPG/400® does not provide the facility for
|
|
setting pointers and the SQLDA uses pointers to locate the appropriate variables,
|
|
you will have to set these pointers outside your RPG/400 application.</p>
|
|
</dd>
|
|
</dl>
|
|
<a name="wq1645"></a>
|
|
<h3 id="wq1645"><a href="rbafzmst02.htm#ToC_1182">Notes</a></h3>
|
|
<p><span class="bold">Closed state of cursors:</span> All cursors in a program
|
|
are in the closed state when: </p>
|
|
<ul>
|
|
<li>The program is called:
|
|
<ul>
|
|
<li>If CLOSQLCSR(*ENDPGM) is specified, all cursors are in the closed state
|
|
each time the program is called.</li>
|
|
<li>If CLOSQLCSR(*ENDSQL) is specified, all cursors are in the closed state
|
|
only the first time the program is called as long as one SQL program remains
|
|
on the call stack.</li>
|
|
<li>If CLOSQLCSR(*ENDJOB) is specified, all cursors are in the closed state
|
|
only the first time the program is called as long as the job remains active.</li>
|
|
<li>If CLOSQLCSR(*ENDMOD) is specified, all cursors are in the closed state
|
|
each time the module is initiated.</li>
|
|
<li>If CLOSQLCSR(*ENDACTGRP) is specified, all cursors are in the closed state
|
|
only the first time the module in the program is initiated in the activation
|
|
group.</li></ul></li>
|
|
<li>A program starts a new unit of work by executing a COMMIT or ROLLBACK
|
|
statement without a HOLD option. Cursors declared with the HOLD option are
|
|
not closed by a COMMIT statement.</li>
|
|
<li>A CONNECT (Type 1) statement was executed.</li></ul>
|
|
<p>A cursor can also be in the closed state because: </p>
|
|
<ul>
|
|
<li>A CLOSE statement was executed.</li>
|
|
<li>A DISCONNECT statement disconnected the connection with which the cursor
|
|
was associated.</li>
|
|
<li>The connection with which the cursor was associated was in the release-pending state
|
|
and a successful COMMIT occurred.</li>
|
|
<li>A CONNECT (Type 1) statement was executed.</li></ul><a id="idx2937" name="idx2937"></a><a id="idx2938" name="idx2938"></a><a id="idx2939" name="idx2939"></a><a id="idx2940" name="idx2940"></a>
|
|
<p>To retrieve rows from the result table of a cursor, the FETCH statement
|
|
must be executed when the cursor is open. The only way to change the state
|
|
of a cursor from closed to open is to execute an OPEN statement.</p>
|
|
<p><a id="idx2941" name="idx2941"></a><a id="idx2942" name="idx2942"></a><span class="bold">Effect of temporary tables:</span> If the result table of a cursor is not read-only,
|
|
its rows are derived during the execution of subsequent FETCH statements.
|
|
The same method may be used for a read-only result table. However, if a result
|
|
table is read-only, DB2 UDB for iSeries may choose to use the temporary table method instead.
|
|
With this method the entire result table is inserted into a temporary table
|
|
during the execution of the OPEN statement. When a temporary table is used,
|
|
the results of a program can differ in several ways: </p>
|
|
<ul>
|
|
<li>An error can occur during OPEN that would otherwise not occur until some
|
|
later FETCH statement.</li>
|
|
<li>The INSERT, UPDATE, and DELETE statements that are executed while the
|
|
cursor is open cannot affect the result table.</li>
|
|
<li>Any NEXT VALUE expressions in the SELECT statement are evaluated for every
|
|
row of the result table during OPEN. Thus, sequence values are generated,
|
|
for every row of the result table during OPEN.</li>
|
|
<li>Any functions are evaluated for every row of the result table during OPEN.
|
|
Thus, any external actions and SQL statements that modify SQL data within
|
|
the functions are performed for every row of the result table during OPEN.</li></ul>
|
|
<p>Conversely, if a temporary table is not used, INSERT, UPDATE,
|
|
and DELETE statements executed while the cursor is open can affect the result
|
|
table, and any NEXT VALUE expressions and functions in the SELECT statement
|
|
are evaluated as each row is fetched. The effect of such operations is not
|
|
always predictable. For example, if cursor CUR is positioned on a row of its
|
|
result table defined as SELECT * FROM T, and a row is inserted into T, the
|
|
effect of that insert on the result table is not predictable because its rows
|
|
are not ordered. A subsequent FETCH CUR might or might not retrieve the new
|
|
row of T.</p>
|
|
<p><a id="idx2943" name="idx2943"></a><span class="bold">Parameter marker replacement:</span> When the SELECT
|
|
statement of the cursor is evaluated, each parameter marker in the statement
|
|
is effectively replaced by its corresponding variable. The replacement of
|
|
a parameter marker is an assignment operation in which the source is the value
|
|
of the variable, and the target is a variable within the database manager.
|
|
For a typed parameter marker, the attributes of the target variable are those
|
|
specified by the CAST specification. For an untyped parameter marker, the
|
|
attributes of the target variable are determined according to the context
|
|
of the parameter marker. For the rules that affect parameter markers, see <a href="rbafzmstpreph2.htm#parmtbl">Table 74</a>.</p>
|
|
<p>Let V denote a variable that corresponds to parameter marker P. The value
|
|
of V is assigned to the target variable for P in accordance with the rules
|
|
for assigning a value to a column. Thus: </p>
|
|
<ul>
|
|
<li>V must be compatible with the target.</li>
|
|
<li>If V is a number, the absolute value of its integral part must not be
|
|
greater than the maximum absolute value of the integral part of the target.</li>
|
|
<li>If the attributes of V are not identical to the attributes of the target,
|
|
the value is converted to conform to the attributes of the target.</li>
|
|
<li>If the target cannot contain nulls, the value of V must not be null.</li></ul>
|
|
<p>However, unlike the rules for assigning a value to a column: </p>
|
|
<ul>
|
|
<li>If V is a string, the value will be truncated (without an error), if its
|
|
length is greater than the length attribute of the target.</li></ul>
|
|
<p>When the SELECT statement of the cursor is evaluated, the value used in
|
|
place of P is the value of the target variable for P. For example, if V is
|
|
CHAR(6), and the target is CHAR(8), the value used in place of P is the value
|
|
of V padded with two blanks.</p>
|
|
<p>The USING clause is intended for a prepared SELECT statement that contains
|
|
parameter markers. However, it can also be used when the SELECT statement
|
|
of the cursor is part of the DECLARE CURSOR statement. In this case the OPEN
|
|
statement is executed as if each variable in the SELECT statement were a parameter
|
|
marker, except that the attributes of the target variables are the same as
|
|
the attributes of the variables in the SELECT statement. The effect is to
|
|
override the values of the variables in the SELECT statement of the cursor
|
|
with the values of the variables specified in the USING clause.</p>
|
|
<a name="wq1646"></a>
|
|
<h3 id="wq1646"><a href="rbafzmst02.htm#ToC_1183">Examples</a></h3>
|
|
<p><span class="italic">Example 1:</span> Write the embedded statements in a COBOL
|
|
program that will: </p>
|
|
<ol type="1">
|
|
<li>Define a cursor C1 that is to be used to retrieve all rows from the DEPARTMENT
|
|
table for departments that are administered by (ADMRDEPT) department 'A00'</li>
|
|
<li>Place the cursor C1 before the first row to be fetched.</li></ol>
|
|
<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' END-EXEC.
|
|
|
|
EXEC SQL <span class="bold">OPEN</span> C1 END-EXEC.</pre>
|
|
<p><span class="italic">Example 2:</span> Code an OPEN statement to associate
|
|
a cursor DYN_CURSOR with a dynamically defined <var class="pv">select-statement</var> in
|
|
a C program. Assume each prepared <var class="pv">select-statement</var> always defines
|
|
two items in its select list with the first item having a data type of integer
|
|
and the second item having a data type of VARCHAR(64). (The related host variable
|
|
definitions, PREPARE statement, and DECLARE CURSOR statement are also shown
|
|
in the example below.) </p>
|
|
<pre class="xmp"> EXEC SQL <span class="bold">BEGIN DECLARE SECTION</span>;
|
|
static short hv_int;
|
|
char hv_vchar64[64];
|
|
char stmt1_str[200];
|
|
EXEC SQL <span class="bold">END DECLARE SECTION</span>;
|
|
|
|
EXEC SQL <span class="bold">PREPARE</span> STMT1_NAME <span class="bold">FROM</span> :stmt1_str;
|
|
|
|
EXEC SQL <span class="bold">DECLARE</span> DYN_CURSOR <span class="bold">CURSOR FOR</span> STMT1_NAME;
|
|
|
|
EXEC SQL <span class="bold">OPEN</span> DYN_CURSOR <span class="bold">USING</span> :hv_int, :hv_vchar64;</pre>
|
|
<p><span class="italic">Example 3:</span> Code an OPEN statement as in example
|
|
3, but in this case the number and data types of the items in the select statement
|
|
are not known. </p>
|
|
<pre class="xmp"> EXEC SQL <span class="bold">BEGIN DECLARE SECTION</span>;
|
|
char stmt1_str[200];
|
|
EXEC SQL <span class="bold">END DECLARE SECTION</span>;
|
|
EXEC SQL <span class="bold">INCLUDE SQLDA</span>;
|
|
|
|
EXEC SQL <span class="bold">PREPARE</span> STMT1_NAME <span class="bold">FROM</span> :stmt1_str;
|
|
EXEC SQL <span class="bold">DECLARE</span> DYN_CURSOR <span class="bold">CURSOR FOR</span> STMT1_NAME;
|
|
|
|
EXEC SQL <span class="bold">OPEN</span> DYN_CURSOR <span class="bold">USING DESCRIPTOR</span> :sqlda;</pre>
|
|
<p> <a id="idx2944" name="idx2944"></a> <a id="idx2945" name="idx2945"></a></p>
|
|
<hr /><br />
|
|
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmsth2lockt.htm">Previous Page</a> | <a href="rbafzmstpreph2.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>
|