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.
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.
For example, the following statement needs to be processed:
SELECT WORKDEPT, PHONENO FROM CORPDATA.EMPLOYEE WHERE LASTNAME = 'PARKER'
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:
EXEC SQL PREPARE S1 FROM :DSTRING;
EXEC SQL ALLOCATE DESCRIPTOR 'mydescr' WITH MAX 20;
EXEC SQL DESCRIBE S1 USING DESCRIPTOR 'mydescr';
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'.
/* Determine the returned SQLCODE from the DESCRIBE statement */ EXEC SQL GET DIAGNOSTICS CONDITION 1: returned_sqlcode = DB2_RETURNED_SQLCODE; if returned_sqlcode = 239 then do; /* Get the second token for the SQLCODE that indicated not enough entries were allocated */ EXEC SQL GET DIAGNOSTICS CONDITION 1: token = DB2_ORDINAL_TOKEN_2; /* Move the token variable from a character host variable into an integer host variable */ EXEC SQL SET :var1 = :token; /* Deallocate the descriptor that is too small */ EXEC SQL DEALLOCATE DESCRIPTOR 'mydescr'; /* Allocate the new descriptor to be the size indicated by the retrieved token */ EXEC SQL ALLOCATE DESCRIPTOR 'mydescr' WITH MAX :var1; /* Perform the describe with the larger descriptor */ EXEC SQL DESCRIBE s1 USING DESCRIPTOR 'mydescr'; end;
EXEC SQL DECLARE C1 CURSOR FOR S1;
EXEC SQL OPEN C1; EXEC SQL FETCH C1 USING SQL DESCRIPTOR '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 FETCH C1 USING SQL DESCRIPTOR 'mydescr'; end; EXEC SQL CLOSE C1;
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.
EXEC SQL GET DESCRIPTOR 'mydescr' :count = COUNT;
do i = 1 to count; GET DESCRIPTOR 'mydescr' VALUE :i /* set entry number to get */ :type = TYPE, /* get the data type */ :length = LENGTH, /* length value */ :result_ind = INDICATOR; if result_ind >= 0 then if type = character GET DESCRIPTOR 'mydescr' VALUE :i :char_result = DATA; /* read data into character field */ else if type = integer GET DESCRIPTOR 'mydescr' VALUE :i :int_result = DATA; /* read data into integer field */ else /* continue checking and processing for all data types that might be returned */ end;
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.
NAME, DB2_SYSTEM_COLUMN_NAME, and DB2_LABEL can be used to get name-related values for the result column. See GET DESCRIPTOR for more information about the items returned for a GET DESCRIPTOR statement and for the definition of the TYPE values