177 lines
9.9 KiB
HTML
177 lines
9.9 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 using an allocated SQL descriptor" />
|
|
<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 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 from another application, or built dynamically by your application." />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafyprocesssqlda.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="rbafyalloexample" />
|
|
<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 using an allocated SQL descriptor</title>
|
|
</head>
|
|
<body id="rbafyalloexample"><a name="rbafyalloexample"><!-- --></a>
|
|
<img src="./delta.gif" alt="Start of change" /><!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
|
<h1 class="topictitle1">Example: Select statement using an allocated SQL descriptor</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 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"><div class="p">Next, you need to determine the number of result columns and their
|
|
data types. To do this, you need to allocate the largest number of entries
|
|
for an SQL descriptor that you think you will need. Assume that no more than
|
|
20 columns are ever expected to be accessed by a single SELECT statement.<pre>EXEC SQL
|
|
<strong>ALLOCATE DESCRIPTOR</strong> 'mydescr' <strong>WITH MAX</strong> 20;</pre>
|
|
</div>
|
|
<div class="p">Now
|
|
that the descriptor is allocated, the DESCRIBE statement can be done to get
|
|
the column information.<pre>EXEC SQL
|
|
<strong>DESCRIBE</strong> S1 <strong>USING DESCRIPTOR</strong> 'mydescr';</pre>
|
|
</div>
|
|
<p>When
|
|
the DESCRIBE statement is run, SQL places values that provide information
|
|
about the statement's select-list into the SQL descriptor area defined by
|
|
'mydescr'.</p>
|
|
<div class="p">If the DESCRIBE determines that not enough entries were allocated
|
|
in the descriptor, SQLCODE +239 is issued. As part of this diagnostic, the
|
|
second replacement text value indicates the number of entries that are needed.
|
|
The following code sample shows how this condition can be detected and shows
|
|
the descriptor allocated with the larger size.<pre>/* Determine the returned SQLCODE from the DESCRIBE statement */
|
|
EXEC SQL
|
|
<strong>GET DIAGNOSTICS CONDITION</strong> 1: returned_sqlcode = <strong>DB2_RETURNED_SQLCODE</strong>;
|
|
|
|
if returned_sqlcode = 239 then do;
|
|
|
|
/* Get the second token for the SQLCODE that indicated
|
|
not enough entries were allocated */
|
|
|
|
EXEC SQL
|
|
<strong>GET DIAGNOSTICS CONDITION</strong> 1: token = <strong>DB2_ORDINAL_TOKEN_2</strong>;
|
|
/* Move the token variable from a character host variable into an integer host variable */
|
|
EXEC SQL
|
|
<strong>SET</strong> :var1 = :token;
|
|
/* Deallocate the descriptor that is too small */
|
|
EXEC SQL
|
|
<strong>DEALLOCATE DESCRIPTOR</strong> 'mydescr';
|
|
/* Allocate the new descriptor to be the size indicated by the retrieved token */
|
|
EXEC SQL
|
|
<strong>ALLOCATE DESCRIPTOR</strong> 'mydescr' <strong>WITH MAX</strong> :var1;
|
|
/* Perform the describe with the larger descriptor */
|
|
EXEC SQL
|
|
<strong>DESCRIBE</strong> s1 <strong>USING DESCRIPTOR</strong> 'mydescr';
|
|
end; </pre>
|
|
</div>
|
|
<div class="p">At this point, the descriptor contains the information
|
|
about the select statement. Now you are ready to retrieve the SELECT statement
|
|
results. For dynamic SQL, the SELECT INTO statement is not allowed. You
|
|
must use a cursor.<pre>EXEC SQL
|
|
<strong>DECLARE</strong> C1 <strong>CURSOR FOR</strong> S1;</pre>
|
|
</div>
|
|
<div class="p">You will notice that the prepared statement name is used
|
|
in the cursor declaration instead of the complete SELECT statement. Now you
|
|
can loop through the selected rows, processing them as you read them. The
|
|
following code sample shows how this is done.<pre>EXEC SQL
|
|
<strong>OPEN</strong> C1;
|
|
|
|
EXEC SQL
|
|
<strong>FETCH</strong> C1 <strong>USING SQL DESCRIPTOR</strong> 'mydescr';
|
|
do while not at end of data;
|
|
|
|
/* process current data returned (see below for discussion of doing this) */
|
|
|
|
/* then read the next row */
|
|
|
|
EXEC SQL
|
|
<strong>FETCH</strong> C1 <strong>USING SQL DESCRIPTOR</strong> 'mydescr';
|
|
end;
|
|
|
|
EXEC SQL
|
|
<strong>CLOSE</strong> C1;</pre>
|
|
</div>
|
|
<p>The cursor is opened. The result rows from the SELECT statement
|
|
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 the descriptor area.</p>
|
|
<div class="p">After the FETCH has
|
|
been processed, you can use the GET DESCRIPTOR statement to read the values.
|
|
First, you must read the header value that indicates how many descriptor entries
|
|
were used.<pre>EXEC SQL
|
|
<strong>GET DESCRIPTOR</strong> 'mydescr' :count = <strong>COUNT</strong>;</pre>
|
|
</div>
|
|
<div class="p">Next you can read information about each of the descriptor
|
|
entries. After you determine the data type of the result column, you can do
|
|
another GET DESCRIPTOR to return the actual value. To get the value of the
|
|
indicator, specify the INDICATOR item. If the value of the INDICATOR item
|
|
is negative, the value of the DATA item is not defined. Until another FETCH
|
|
is done, the descriptor items will maintain their values.<pre>do i = 1 to count;
|
|
<strong>GET DESCRIPTOR</strong> 'mydescr' <strong>VALUE</strong> :i /* set entry number to get */
|
|
:type = <strong>TYPE</strong>, /* get the data type */
|
|
:length = <strong>LENGTH</strong>, /* length value */
|
|
:result_ind = <strong>INDICATOR</strong>;
|
|
if result_ind >= 0 then
|
|
if type = character
|
|
<strong>GET DESCRIPTOR</strong> 'mydescr' <strong>VALUE</strong> :i
|
|
:char_result = <strong>DATA</strong>; /* read data into character field */
|
|
else
|
|
if type = integer
|
|
<strong>GET DESCRIPTOR</strong> 'mydescr' <strong>VALUE</strong> :i
|
|
:int_result = <strong>DATA</strong>; /* read data into integer field */
|
|
else
|
|
/* continue checking and processing for all data types that might be returned */
|
|
end;</pre>
|
|
</div>
|
|
</div>
|
|
<div class="section"><p>There are several other descriptor items that you might need to
|
|
check to determine how to handle the result data. PRECISION, SCALE, DB2_CCSID,
|
|
and DATETIME_INTERVAL_CODE are among them. The host variable that has the
|
|
DATA value read into it must have the same data type and CCSID as the data
|
|
being read. If the data type is varying length, the host variable can be
|
|
declared longer than the actual data. For all other data types, the length
|
|
must match exactly.</p>
|
|
<p>NAME, DB2_SYSTEM_COLUMN_NAME, and DB2_LABEL can
|
|
be used to get name-related values for the result column. See <a href="../db2/rbafzgetdescr.htm#getdescr.htm">GET DESCRIPTOR</a> for more
|
|
information about the items returned for a GET DESCRIPTOR statement and for
|
|
the definition of the TYPE values</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>
|
|
<img src="./deltaend.gif" alt="End of change" /></body>
|
|
</html> |