ibm-information-center/dist/eclipse/plugins/i5OS.ic.sqlp_5.4.0.1/rbafydynexample.htm

376 lines
20 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 lang="en-us" xml:lang="en-us">
<head>
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
<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="DC.Type" content="reference" />
<meta name="DC.Title" content="Example: Select-statement for allocating storage for SQLDA" />
<meta name="abstract" content="Suppose your application needs to be able to handle a dynamic SELECT statement, one that changes from one use to the next. This statement can be read from a display, passed in from another application, or built dynamically by your application." />
<meta name="description" content="Suppose your application needs to be able to handle a dynamic SELECT statement, one that changes from one use to the next. This statement can be read from a display, passed in from another application, or built dynamically by your application." />
<meta name="DC.subject" content="dynamic SQL, example of allocating storage for SQLDA, examples, SELECT statement allocating storage for SQLDA, SELECT statement, example of allocating storage for SQLDA, SQLDA (SQL descriptor area), SELECT statement for allocating storage for SQLDA, INTO clause, restriction, clause, INTO, restrictions in dynamic SQL, allocating storage for SQLDA, SQLDA (SQL descriptor area), allocating storage for, USING, retrieving SELECT statement result, cursor, retrieving SELECT statement result, SELECT statement result, cursor, using, FETCH statement, dynamic SQL, statements, FETCH" />
<meta name="keywords" content="dynamic SQL, example of allocating storage for SQLDA, examples, SELECT statement allocating storage for SQLDA, SELECT statement, example of allocating storage for SQLDA, SQLDA (SQL descriptor area), SELECT statement for allocating storage for SQLDA, INTO clause, restriction, clause, INTO, restrictions in dynamic SQL, allocating storage for SQLDA, SQLDA (SQL descriptor area), allocating storage for, USING, retrieving SELECT statement result, cursor, retrieving SELECT statement result, SELECT statement result, cursor, using, FETCH statement, dynamic SQL, statements, FETCH" />
<meta name="DC.Relation" scheme="URI" content="rbafyprocesssqlda.htm" />
<meta name="DC.Relation" scheme="URI" content="rbafyvarlst.htm" />
<meta name="DC.Relation" scheme="URI" content="rbafysqldaformat.htm" />
<meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" />
<meta name="DC.Rights.Owner" content="(C) Copyright IBM Corporation 1998, 2006" />
<meta name="DC.Format" content="XHTML" />
<meta name="DC.Identifier" content="rbafydynexample" />
<meta name="DC.Language" 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. -->
<link rel="stylesheet" type="text/css" href="./ibmdita.css" />
<link rel="stylesheet" type="text/css" href="./ic.css" />
<title>Example: Select-statement for allocating storage for SQLDA</title>
</head>
<body id="rbafydynexample"><a name="rbafydynexample"><!-- --></a>
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
<h1 class="topictitle1">Example: Select-statement for allocating storage for SQLDA</h1>
<div><p><span>Suppose your application needs to be able
to handle a dynamic SELECT statement, one that changes from one use to the
next. This statement can be read from a display, passed in from another application,
or built dynamically by your application.</span></p>
<div class="section"><p>In other words, you don't know exactly what this statement is
going to be returning every time. Your application needs to be able to handle
the varying number of result columns with data types that are unknown ahead
of time.</p>
</div>
<div class="section"><p>For example, the following statement needs to be processed:</p>
<pre> <strong>SELECT</strong> WORKDEPT, PHONENO
<strong>FROM</strong> CORPDATA.EMPLOYEE
<strong>WHERE</strong> LASTNAME = 'PARKER'</pre>
<div class="note"><span class="notetitle">Note:</span> This SELECT statement
has no INTO clause. Dynamic SELECT statements must <em>not</em> have an INTO
clause, even if they return only one row.</div>
</div>
<div class="section"><p>The statement is assigned to a host variable. The host variable,
in this case named DSTRING, is then processed by using the PREPARE statement
as shown:</p>
<pre>EXEC SQL
<strong>PREPARE</strong> S1 <strong>FROM</strong> :DSTRING;</pre>
</div>
<div class="section"><p>Next, you need to determine the number of result columns and their
data types. To do this, you need an SQLDA.</p>
</div>
<div class="section"><p>The first step in defining an SQLDA, is to allocate storage for
it. (Allocating storage is not necessary in REXX.) The techniques for acquiring
storage are language dependent. The SQLDA must be allocated on a 16-byte boundary.
The SQLDA consists of a fixed-length header that is 16 bytes in length. The
header is followed by a varying-length array section (SQLVAR), each element
of which is 80 bytes in length. </p>
</div>
<div class="section"><p>The amount of storage that you need to allocate depends on how
many elements you want to have in the SQLVAR array. Each column you select
must have a corresponding SQLVAR array element. Therefore, the number of columns
listed in your SELECT statement determines how many SQLVAR array elements
you should allocate. Since this SELECT statement was specified at run time,
it is impossible to know exactly how many columns will be accessed. Consequently,
you must estimate the number of columns. Suppose, in this example, that no
more than 20 columns are ever expected to be accessed by a single SELECT statement.
In this case, the SQLVAR array should have a dimension of 20, ensuring that
each item in the select-list has a corresponding entry in SQLVAR. This makes
the total SQLDA size 20 x 80, or 1600, plus 16 for a total of 1616 bytes</p>
</div>
<div class="section"><p>Having allocated what you estimated to be enough space for your
SQLDA, you need to set the SQLN field of the SQLDA equal to the number of
SQLVAR array elements, in this case 20.</p>
</div>
<div class="section"><p>Having allocated storage and initialized the size, you can now
issue a DESCRIBE statement.</p>
<pre>EXEC SQL
<strong>DESCRIBE</strong> S1 <strong>INTO</strong> :SQLDA;</pre>
</div>
<div class="section"><p>When the DESCRIBE statement is run, SQL places values in the SQLDA
that provide information about the select-list for your statement. The following
tables show the contents of the SQLDA after the DESCRIBE is run. Only the
entries that are meaningful in this context are shown.</p>
</div>
<div class="section"><p>The SQLDA header contains:</p>
</div>
<div class="section"><div class="p">
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 1. SQLDA header</caption><thead align="left"><tr><th valign="top" id="d0e163">Description</th>
<th valign="top" id="d0e165">Value</th>
</tr>
</thead>
<tbody><tr><td valign="top" headers="d0e163 ">SQLAID</td>
<td valign="top" headers="d0e165 ">'SQLDA'</td>
</tr>
<tr><td valign="top" headers="d0e163 ">SQLDABC</td>
<td valign="top" headers="d0e165 ">1616</td>
</tr>
<tr><td valign="top" headers="d0e163 ">SQLN</td>
<td valign="top" headers="d0e165 ">20</td>
</tr>
<tr><td valign="top" headers="d0e163 ">SQLD</td>
<td valign="top" headers="d0e165 ">2</td>
</tr>
</tbody>
</table>
</div>
</div>
</div>
<div class="section"><p>SQLDAID is an identifier field initialized by SQL when a DESCRIBE
is run. SQLDABC is the byte count or size of the SQLDA. The SQLDA header
is followed by 2 occurrences of the SQLVAR structure, one for
each column in the result table of the SELECT statement being described:</p>
</div>
<div class="section"><div class="p">
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 2. SQLVAR element 1</caption><thead align="left"><tr><th valign="top" width="50.25125628140703%" id="d0e202">Description</th>
<th valign="top" width="49.74874371859296%" id="d0e204">Value</th>
</tr>
</thead>
<tbody><tr><td valign="top" width="50.25125628140703%" headers="d0e202 ">SQLTYPE</td>
<td valign="top" width="49.74874371859296%" headers="d0e204 ">453</td>
</tr>
<tr><td valign="top" width="50.25125628140703%" headers="d0e202 ">SQLLEN</td>
<td valign="top" width="49.74874371859296%" headers="d0e204 ">3</td>
</tr>
<tr><td valign="top" width="50.25125628140703%" headers="d0e202 ">SQLDATA (3:4)</td>
<td valign="top" width="49.74874371859296%" headers="d0e204 ">37</td>
</tr>
<tr><td valign="top" width="50.25125628140703%" headers="d0e202 ">SQLNAME</td>
<td valign="top" width="49.74874371859296%" headers="d0e204 ">8 WORKDEPT</td>
</tr>
</tbody>
</table>
</div>
</div>
</div>
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 3. SQLVAR element 2</caption><thead align="left"><tr><th valign="top" id="d0e235">Description</th>
<th valign="top" id="d0e237">Value</th>
</tr>
</thead>
<tbody><tr><td valign="top" headers="d0e235 ">SQLTYPE</td>
<td valign="top" headers="d0e237 ">453</td>
</tr>
<tr><td valign="top" headers="d0e235 ">SQLLEN</td>
<td valign="top" headers="d0e237 ">4</td>
</tr>
<tr><td valign="top" headers="d0e235 ">SQLDATA(3:4)</td>
<td valign="top" headers="d0e237 ">37</td>
</tr>
<tr><td valign="top" headers="d0e235 ">SQLNAME</td>
<td valign="top" headers="d0e237 ">7 PHONENO</td>
</tr>
</tbody>
</table>
</div>
<div class="section"><p>Your program might need to alter the SQLN value if the SQLDA is
not large enough to contain the described SQLVAR elements. For example, suppose
that instead of the estimated maximum of 20 columns, the SELECT statement
actually returns 27. SQL cannot describe this select-list because the SQLVAR
needs more elements than the allocated space allows. Instead, SQL sets the
SQLD to the actual number of columns specified by the SELECT statement and
the remainder of the structure is ignored. Therefore, after a DESCRIBE, you
should compare the SQLN value to the SQLD value. If the value of SQLD is
greater than the value of SQLN, allocate a larger SQLDA based on the value
in SQLD, as follows, and perform the DESCRIBE again:</p>
<pre>EXEC SQL
<strong>DESCRIBE</strong> S1 <strong>INTO</strong> :SQLDA;
IF SQLN &lt;= SQLD THEN
DO;
/*Allocate a larger SQLDA using the value of SQLD.*/
/*Reset SQLN to the larger value.*/
EXEC SQL
<strong>DESCRIBE</strong> S1 <strong>INTO</strong> :SQLDA;
END;</pre>
</div>
<div class="section"><p>If you use DESCRIBE on a non SELECT statement, SQL sets SQLD to
0. Therefore, if your program is designed to process both SELECT and non
SELECT statements, you can describe each statement after it is prepared to
determine whether it is a SELECT statement. This example is designed to process
only SELECT statements; the SQLD value is not checked.</p>
</div>
<div class="section"><p>Your program must now analyze the elements of SQLVAR returned
from the successful DESCRIBE. The first item in the select-list is WORKDEPT.
In the SQLTYPE field, the DESCRIBE returns a value for the data type of the
expression and whether nulls are applicable or not.</p>
</div>
<div class="section"><p>In this example, SQL sets SQLTYPE to 453 in SQLVAR element 1.
This specifies that WORKDEPT is a fixed-length character string result column
and that nulls are permitted in the column.</p>
</div>
<div class="section"><p>SQL sets SQLLEN to the length of the column. Because the data
type of WORKDEPT is CHAR, SQL sets SQLLEN equal to the length of the character
column. For WORKDEPT, that length is 3. Therefore, when the SELECT statement
is later run, a storage area large enough to hold a CHAR(3) string will be
needed.</p>
</div>
<div class="section"><p>Because the data type of WORKDEPT is CHAR FOR SBCS DATA, the first
4 bytes of SQLDATA were set to the CCSID of the character column.</p>
</div>
<div class="section"><p>The last field in an SQLVAR element is a varying-length character
string called SQLNAME. The first 2 bytes of SQLNAME contain the length of
the character data. The character data itself is typically the name of a column
used in the SELECT statement, in this case WORKDEPT. The exceptions to this
are select-list items that are unnamed, such as functions (for example, SUM(SALARY)),
expressions (for example, A+B-C), and constants. In these cases, SQLNAME is
an empty string. SQLNAME can also contain a label rather than a name. One
of the parameters associated with the PREPARE and DESCRIBE statements is the
USING clause. You can specify it this way:</p>
<pre>EXEC SQL
<strong>DESCRIBE</strong> S1 <strong>INTO</strong>:SQLDA
<strong>USING</strong> LABELS;</pre>
</div>
<div class="section"><p>If you specify:</p>
</div>
<div class="section"> <dl><dt class="dlterm">NAMES (or omit the USING parameter entirely)</dt>
<dd>Only column names are placed in the SQLNAME field.</dd>
<dt class="dlterm">SYSTEM NAMES</dt>
<dd>Only the system column names are placed in the SQLNAME field.</dd>
<dt class="dlterm">LABELS</dt>
<dd>Only labels associated with the columns listed in your SQL statement are
entered here.</dd>
<dt class="dlterm">ANY</dt>
<dd>Labels are placed in the SQLNAME field for those columns that have labels;
otherwise, the column names are entered.</dd>
<dt class="dlterm">BOTH</dt>
<dd>Names and labels are both placed in the field with their corresponding
lengths. Remember to double the size of the SQLVAR array because you are including
twice the number of elements.</dd>
<dt class="dlterm">ALL</dt>
<dd>Column names, labels, and system column names are placed in the field
with their corresponding lengths. Remember to triple the size of the SQLVAR
array</dd>
</dl>
</div>
<div class="section"><p>In this example, the second SQLVAR element contains the information
for the second column used in the select: PHONENO. The 453 code in SQLTYPE
specifies that PHONENO is a CHAR column. SQLLEN is set to 4.</p>
</div>
<div class="section"><p>Now you need to set up to use the SQLDA to retrieve values when
running the SELECT statement.</p>
</div>
<div class="section"><p>After analyzing the result of the DESCRIBE, you can allocate storage
for variables that are to contain the result of the SELECT statement. For
WORKDEPT, a character field of length 3 must be allocated; for PHONENO, a
character field of length 4 must be allocated. Since both of these results
can be the NULL value, an indicator variable must be allocated for each field
as well.</p>
</div>
<div class="section"><p>After the storage is allocated, you must set SQLDATA and SQLIND
to point to the allocated storage areas. For each element of the SQLVAR array,
SQLDATA points to the place where the result value is to be put. SQLIND points
to the place where the null indicator value is to be put. The following tables
show what the structure looks like now. Only the entries that are meaningful
in this context are shown:</p>
</div>
<div class="section"><div class="p">
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 4. SQLDA header</caption><thead align="left"><tr><th valign="top" id="d0e365">Description</th>
<th valign="top" id="d0e367">Value</th>
</tr>
</thead>
<tbody><tr><td valign="top" headers="d0e365 ">SQLAID</td>
<td valign="top" headers="d0e367 ">'SQLDA'</td>
</tr>
<tr><td valign="top" headers="d0e365 ">SQLDABC</td>
<td valign="top" headers="d0e367 ">1616</td>
</tr>
<tr><td valign="top" headers="d0e365 ">SQLN</td>
<td valign="top" headers="d0e367 ">20</td>
</tr>
<tr><td valign="top" headers="d0e365 ">SQLD</td>
<td valign="top" headers="d0e367 ">2</td>
</tr>
</tbody>
</table>
</div>
</div>
</div>
<div class="section"><div class="p">
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 5. SQLVAR element 1</caption><thead align="left"><tr><th valign="top" id="d0e401">Description</th>
<th valign="top" id="d0e403">Value</th>
</tr>
</thead>
<tbody><tr><td valign="top" headers="d0e401 ">SQLTYPE</td>
<td valign="top" headers="d0e403 ">453</td>
</tr>
<tr><td valign="top" headers="d0e401 ">SQLLEN</td>
<td valign="top" headers="d0e403 ">3</td>
</tr>
<tr><td valign="top" headers="d0e401 ">SQLDATA</td>
<td valign="top" headers="d0e403 ">Pointer to area for CHAR(3) result</td>
</tr>
<tr><td valign="top" headers="d0e401 ">SQLIND</td>
<td valign="top" headers="d0e403 ">Pointer to 2 byte integer indicator for result column</td>
</tr>
</tbody>
</table>
</div>
</div>
</div>
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 6. SQLVAR element 2</caption><thead align="left"><tr><th valign="top" id="d0e434">Description</th>
<th valign="top" id="d0e436">Value</th>
</tr>
</thead>
<tbody><tr><td valign="top" headers="d0e434 ">SQLTYPE</td>
<td valign="top" headers="d0e436 ">453</td>
</tr>
<tr><td valign="top" headers="d0e434 ">SQLLEN</td>
<td valign="top" headers="d0e436 ">4 </td>
</tr>
<tr><td valign="top" headers="d0e434 ">SQLDATA</td>
<td valign="top" headers="d0e436 ">Pointer to area for CHAR(4) result</td>
</tr>
<tr><td valign="top" headers="d0e434 ">SQLIND</td>
<td valign="top" headers="d0e436 ">Pointer to 2 byte integer indicator for result column</td>
</tr>
</tbody>
</table>
</div>
<div class="section"><p>You are now ready to retrieve the SELECT statements results. Dynamically
defined SELECT statements must not have an INTO statement. Therefore, all
dynamically defined SELECT statements must use a cursor. Special forms of
the DECLARE, OPEN, and FETCH are used for dynamically defined SELECT statements.</p>
</div>
<div class="section"><p>The DECLARE statement for the example statement is:</p>
<pre>EXEC <strong>SQL DECLARE</strong> C1 <strong>CURSOR FOR</strong> S1;</pre>
</div>
<div class="section"><p>As you can see, the only difference is that the name of the prepared
SELECT statement (S1) is used instead of the SELECT statement itself. The
actual retrieval of result rows is made as follows:</p>
<pre>EXEC SQL
<strong>OPEN</strong> C1;
EXEC SQL
<strong>FETCH</strong> C1 <strong>USING DESCRIPTOR</strong> :SQLDA;
DO WHILE (SQLCODE = 0);
/*Process the results pointed to by SQLDATA*/
EXEC SQL
<strong>FETCH</strong> C1 <strong>USING DESCRIPTOR</strong> :SQLDA;
END;
EXEC SQL
<strong>CLOSE</strong> C1;</pre>
</div>
<div class="section"><p>The cursor is opened. The result rows from the SELECT are then
returned one at a time using a FETCH statement. On the FETCH statement, there
is no list of output host variables. Instead, the FETCH statement tells SQL
to return results into areas described by your SQLDA. The results are returned
into the storage areas pointed to by the SQLDATA and SQLIND fields of the
SQLVAR elements. After the FETCH statement has been processed, the SQLDATA
pointer for WORKDEPT has its referenced value set to 'E11'. Its corresponding
indicator value is 0 since a non-null value was returned. The SQLDATA pointer
for PHONENO has its referenced value set to '4502'. Its corresponding indicator
value is also 0 since a non-null value was returned.</p>
</div>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="rbafyprocesssqlda.htm" title="There are two basic types of SELECT statements: fixed list and varying list.">Process SELECT statements and use a descriptor</a></div>
</div>
<div class="relref"><strong>Related reference</strong><br />
<div><a href="rbafyvarlst.htm" title="In dynamic SQL, varying-list SELECT statements are ones for which the number and format of result columns to be returned are not predictable; that is, you do not know how many variables you need, or what the data types are.">Varying-list SELECT statements</a></div>
<div><a href="rbafysqldaformat.htm" title="The SQLDA consists of four variables followed by an arbitrary number of occurrences of a sequence of six variables collectively named SQLVAR.">SQLDA format</a></div>
</div>
</div>
</body>
</html>