SQL Reference
The DESCRIBE statement obtains information about a prepared
statement. For an explanation of prepared statements, see PREPARE.
Invocation
This statement can be embedded only in an application program. It is
an executable statement that cannot be dynamically prepared.
Authorization
None required.
Syntax
>>-DESCRIBE--statement-name--INTO--descriptor-name-------------><
Description
- statement-name
- Identifies the statement about which information is required. When
the DESCRIBE statement is executed, the name must identify a prepared
statement.
- INTO descriptor-name
- Identifies an SQL descriptor area (SQLDA), which is described in Appendix C, SQL Descriptor Area (SQLDA). Before the DESCRIBE statement is executed, the
following variables in the SQLDA must be set:
- SQLN
- Indicates the number of variables represented by SQLVAR. (SQLN
provides the dimension of the SQLVAR array.) SQLN must be set to a
value greater than or equal to zero before the DESCRIBE statement is
executed.
When the DESCRIBE statement is executed, the database manager assigns
values to the variables of the SQLDA as follows:
- SQLDAID
- The first 6 bytes are set to 'SQLDA ' (that is, 5 letters
followed by the space character).
The seventh byte, called SQLDOUBLED, is set to '2' if the SQLDA
contains two SQLVAR entries for every select-list item (or, column
of the result table). This technique is used in order to accommodate
LOB, distinct or reference type result columns. Otherwise, SQLDOUBLED is set to the space
character.
The doubled flag is set to space if there is not enough room in the SQLDA
to contain the entire DESCRIBE reply.
The eighth byte is set to the space character.
- SQLDABC
- Length of the SQLDA.
- SQLD
- If the prepared statement is a SELECT, the number of columns in its result
table; otherwise, 0.
- SQLVAR
- If the value of SQLD is 0, or greater than the value of SQLN, no values
are assigned to occurrences of SQLVAR.
If the value is n, where n is greater than 0 but less
than or equal to the value of SQLN, values are assigned to the first
n occurrences of SQLVAR so that the first occurrence of SQLVAR
contains a description of the first column of the result table, the second
occurrence of SQLVAR contains a description of the second column of the result
table, and so on. The description of a column consists of the values
assigned to SQLTYPE, SQLLEN, SQLNAME, SQLLONGLEN, and
SQLDATATYPE_NAME.
Basic SQLVAR
- SQLTYPE
- A code showing the data type of the column and whether or not it can
contain null values.
- SQLLEN
- A length value depending on the data type of the result columns.
SQLLEN is 0 for LOB data types.
- SQLNAME
- If the derived column is not a simple column reference, then sqlname
contains an ASCII numeric literal value, which represents the derived
column's original position within the select list; otherwise, sqlname
contains the name of the column.
Secondary SQLVAR
These variables are only used if the number of SQLVAR entries are doubled
to accommodate LOB or distinct type columns.
- SQLLONGLEN
- The length attribute of a BLOB, CLOB, or DBCLOB column.
- SQLDATATYPE_NAME
- For a distinct type column, the database manager sets this to the fully
qualified distinct type name. Otherwise, schema name is SYSIBM and the
low order portion of the name is the name in the TYPENAME column of the
SYSCAT.DATATYPES catalog view.
Notes
- Before the DESCRIBE statement is executed, the value of SQLN must be set
to indicate how many occurrences of SQLVAR are provided in the SQLDA and
enough storage must be allocated to contain SQLN occurrences. To obtain
the description of the columns of the result table of a prepared SELECT
statement, the number of occurrences of SQLVAR must not be less than the
number of columns.
- If a LOB of a large size is expected, then remember that
manipulating this large object will affect application memory. Given this condition, consider using locators or file reference
variables. Modify the SQLDA after the DESCRIBE statement is executed
but prior to allocating storage so that an SQLTYPE of SQL_TYP_xLOB is changed
to SQL_TYP_xLOB_LOCATOR or SQL_TYP_xLOB_FILE with corresponding changes to
other fields such as SQLLEN. Then allocate storage based on SQLTYPE and
continue.
See the Application Development Guide for more information on using locators and file reference variables with the
SQLDA.
- Code page conversions between extended Unix code (EUC) code pages and DBCS
code pages can result in the expansion and contraction of character
lengths. See the Application Development Guide for information on handling such situations.
- Allocating the SQLDA: Among the possible ways to
allocate the SQLDA are the three described below.
First Technique: Allocate an SQLDA with enough
occurrences of SQLVAR to accommodate any select list that the application will
have to process. If the table contains any LOB or distinct type
columns, the number of SQLVARs should be double the maximum number of columns;
otherwise the number should be the same as the maximum number of
columns. Having done the allocation, the application can use this SQLDA
repeatedly.
This technique uses a large amount of storage that is never deallocated,
even when most of this storage is not used for a particular select
list.
Second Technique: Repeat the following two steps for
every processed select list:
- Execute a DESCRIBE statement with an SQLDA that has no occurrences of
SQLVAR; that is, an SQLDA for which SQLN is zero. The value returned
for SQLD is the number of columns in the result table. This is either
the required number of occurrences of SQLVAR or half the required
number. Because there were no SQLVAR entries, a warning with SQLSTATE
01005 will be issued. If the SQLCODE accompanying that warning is equal
to one of +237, +238 or +239, the number of SQLVAR entries should be double
the value returned in SQLD.
82
- Allocate an SQLDA with enough occurrences of SQLVAR. Then execute
the DESCRIBE statement again, using this new SQLDA.
This technique allows better storage management than the first technique,
but it doubles the number of DESCRIBE statements.
Third Technique: Allocate an SQLDA that is large
enough to handle most, and perhaps all, select lists but is also reasonably
small. Execute DESCRIBE and check the SQLD value. Use the SQLD
value for the number of occurrences of SQLVAR to allocate a larger SQLDA, if
necessary.
This technique is a compromise between the first two techniques. Its
effectiveness depends on a good choice of size for the original SQLDA.
Example
In a C program, execute a DESCRIBE statement with an SQLDA that has no
occurrences of SQLVAR. If SQLD is greater than zero, use the value to
allocate an SQLDA with the necessary number of occurrences of SQLVAR and then
execute a DESCRIBE statement using that SQLDA.
EXEC SQL BEGIN DECLARE SECTION;
char stmt1_str[200];
EXEC SQL END DECLARE SECTION;
EXEC SQL INCLUDE SQLDA;
EXEC SQL DECLARE DYN_CURSOR CURSOR FOR STMT1_NAME;
... /* code to prompt user for a query, then to generate */
/* a select-statement in the stmt1_str */
EXEC SQL PREPARE STMT1_NAME FROM :stmt1_str;
... /* code to set SQLN to zero and to allocate the SQLDA */
EXEC SQL DESCRIBE STMT1_NAME INTO :sqlda;
... /* code to check that SQLD is greater than zero, to set */
/* SQLN to SQLD, then to re-allocate the SQLDA */
EXEC SQL DESCRIBE STMT1_NAME INTO :sqlda;
... /* code to prepare for the use of the SQLDA */
/* and allocate buffers to receive the data */
EXEC SQL OPEN DYN_CURSOR;
... /* loop to fetch rows from result table */
EXEC SQL FETCH DYN_CURSOR USING DESCRIPTOR :sqlda;
.
.
.
Footnotes:
- 82
-
The return of these positive SQLCODEs assumes that the SQLWARN bind option
setting was YES (return positive SQLCODEs). If SQLWARN was set to NO,
+238 is still returned to indicate that the number of SQLVAR entries must be
double the value returned in SQLD.
[ Top of Page | Previous Page | Next Page | Table of Contents | Index ]
[ DB2 List of Books |
Search the DB2 Books ]