A named SQL descriptor area consists of a header, which contains information concerning the entire descriptor, and one or more item descriptor areas, which basically each describe one column in the result row.
Before you can use an SQL descriptor area, you need to allocate one:
EXEC SQL ALLOCATE DESCRIPTOR identifier END-EXEC.
The identifier serves as the "variable name" of the descriptor area. When you don't need the descriptor anymore, you should deallocate it:
EXEC SQL DEALLOCATE DESCRIPTOR identifier END-EXEC.
To use a descriptor area, specify it as the storage target in an INTO clause, instead of listing host variables:
EXEC SQL FETCH NEXT FROM mycursor INTO SQL DESCRIPTOR mydesc END-EXEC.
If the result set is empty, the Descriptor Area will still contain the metadata from the query, i.e. the field names.
For not yet executed prepared queries, the DESCRIBE statement can be used to get the metadata of the result set:
EXEC SQL BEGIN DECLARE SECTION END-EXEC. 01 SQL-STMT PIC X(30) VARYING. EXEC SQL END DECLARE SECTION END-EXEC. MOVE "SELECT * FROM table1" TO ARR OF SQL-STMT. COMPUTE LEN OF SQL-STMT = FUNCTION STORED-CHAR-LENGTH ( ARR OF SQL-STMT ) . EXEC SQL PREPARE STMT1 FROM :SQL-STMT END-EXEC. EXEC SQL DESCRIBE STMT1 INTO SQL DESCRIPTOR MYDESC END-EXEC.
Before PostgreSQL 9.0, the SQL keyword was optional, so using DESCRIPTOR and SQL DESCRIPTOR produced named SQL Descriptor Areas. Now it is mandatory, omitting the SQL keyword is regarded as the syntax that produces SQLDA Descriptor Areas. However, ecobpg does not support SQLDA and it causes an error.
In DESCRIBE and FETCH statements, the INTO and USING keywords can be used to similarly: they produce the result set and the metadata in a Descriptor Area.
Now how do you get the data out of the descriptor area? You can think of the descriptor area as a group item with named fields. To retrieve the value of a field from the header and store it into a host variable, use the following command:
EXEC SQL GET DESCRIPTOR name :hostvar = field END-EXEC.
Currently, there is only one header field defined: COUNT, which tells how many item descriptor areas exist (that is, how many columns are contained in the result). The host variable needs to be of an integer type as PIC S9(9) COMP-5. To get a field from the item descriptor area, use the following command:
EXEC SQL GET DESCRIPTOR name VALUE num :hostvar = field END-EXEC.
num can be a host variable containing an integer as PIC S9(9) COMP-5.
hostvar must be PIC S9(9) COMP-5 if type of the field is integer. Possible fields are:
number of rows in the result set
actual data item (therefore, the data type of this field depends on the query)
When TYPE is 9, DATETIME_INTERVAL_CODE will have a value of 1 for DATE, 2 for TIME, 3 for TIMESTAMP, 4 for TIME WITH TIME ZONE, or 5 for TIMESTAMP WITH TIME ZONE.
not implemented
the indicator (indicating a null value or a value truncation)
not implemented
length of the datum in characters
name of the column
not implemented
length of the character representation of the datum in bytes
precision (for type numeric)
length of the datum in characters
length of the character representation of the datum in bytes
scale (for type numeric)
numeric code of the data type of the column
In EXECUTE, DECLARE and OPEN statements, the effect of the INTO and USING keywords are different. A Descriptor Area can also be manually built to provide the input parameters for a query or a cursor and USING SQL DESCRIPTOR name is the way to pass the input parameters into a parametrized query. The statement to build a named SQL Descriptor Area is below:
EXEC SQL SET DESCRIPTOR name VALUE num field = :hostvar END-EXEC.
PostgreSQL supports retrieving more that one record in one FETCH statement and storing the data in host variables in this case assumes that the variable is an array. E.g.:
EXEC SQL BEGIN DECLARE SECTION END-EXEC. 01 GROUP-ITEM. 05 IDNUM PIC S9(9) COMP OCCURS 5. EXEC SQL END DECLARE SECTION END-EXEC. EXEC SQL FETCH 5 FROM mycursor INTO SQL DESCRIPTOR mydesc END-EXEC. EXEC SQL GET DESCRIPTOR mydesc VALUE 1 :IDNUM = DATA END-EXEC.