Handling Non-primitive SQL Data Types
This section describes how to handle non-scalar and user-defined SQL-level data types in ECPG applications. Note that this is distinct from the handling of host variables of non-primitive types described in Host Variables with Non-primitive Types.
- Arrays
Multi-dimensional SQL-level arrays are not directly supported in ECPG. One-dimensional SQL-level arrays can be mapped into C array host variables and vice-versa. However, when creating a statement, ECPG does not know the types of the columns, so that it cannot check if a C array is input into a corresponding SQL-level array. When processing the output of an SQL statement, ECPG has to check if both are arrays.
If a query accesses elements of an array separately, a host variable with a type that can be mapped to the element type should be used. For example, if a column type is array of integer, a host variable of type int can be used. Also if the element type is varchar or text, a host variable of type char[] or VARCHAR[] can be used.
Example:CREATE TABLE t3 ( ii integer[] ); testdb=> SELECT * FROM t3; ii ------------- {1,2,3,4,5} (1 row)
The following example retrieves the fourth element of an array and stores it in a host variable of the int type:EXEC SQL BEGIN DECLARE SECTION; int ii; EXEC SQL END DECLARE SECTION; EXEC SQL DECLARE cur1 CURSOR FOR SELECT ii[4] FROM t3; EXEC SQL OPEN cur1; EXEC SQL WHENEVER NOT FOUND DO BREAK; while (1) { EXEC SQL FETCH FROM cur1 INTO :ii ; printf("ii=%d\n", ii); } EXEC SQL CLOSE cur1;
Example output:ii=4
To map multiple array elements to the multiple elements in an array type host variable, each element of the array column and each element of the host variable array must be managed separately. For example:EXEC SQL BEGIN DECLARE SECTION; int ii_a[8]; EXEC SQL END DECLARE SECTION; EXEC SQL DECLARE cur1 CURSOR FOR SELECT ii[1], ii[2], ii[3], ii[4] FROM t3; EXEC SQL OPEN cur1; EXEC SQL WHENEVER NOT FOUND DO BREAK; while (1) { EXEC SQL FETCH FROM cur1 INTO :ii_a[0], :ii_a[1], :ii_a[2], :ii_a[3]; ... }
Note:EXEC SQL BEGIN DECLARE SECTION; int ii_a[8]; EXEC SQL END DECLARE SECTION; EXEC SQL DECLARE cur1 CURSOR FOR SELECT ii FROM t3; EXEC SQL OPEN cur1; EXEC SQL WHENEVER NOT FOUND DO BREAK; while (1) { /* Error */ EXEC SQL FETCH FROM cur1 INTO :ii_a; ... }
It does not work out because you cannot map an array type column to an array host variable directly.
- Composite types
Composite types are not directly supported in ECPG. For example, you cannot declare member variables as date type in a structure. However, you can access each attribute separately or use the external string representation.
In the following example, each attribute can be accessed separately:CREATE TYPE comp_t AS (intval integer, textval varchar(32)); CREATE TABLE t4 (compval comp_t); INSERT INTO t4 VALUES ( (256, 'GaussDB') );
The following program retrieves data from the example table by selecting each attribute of the comp_t type separately:EXEC SQL BEGIN DECLARE SECTION; int intval; varchar textval[33]; EXEC SQL END DECLARE SECTION; /* Put each element of the composite type column in the SELECT list. */ EXEC SQL DECLARE cur1 CURSOR FOR SELECT (compval).intval, (compval).textval FROM t4; EXEC SQL OPEN cur1; EXEC SQL WHENEVER NOT FOUND DO BREAK; while (1) { /* Fetch each element of the composite type column into host variables. */ EXEC SQL FETCH FROM cur1 INTO :intval, :textval; printf("intval=%d, textval=%s\n", intval, textval.arr); } EXEC SQL CLOSE cur1;
The host variables storing values in the FETCH command can be gathered into one structure. For more details about the host variables in the structure form, see Handling Character Strings. In the following example, the two host variables, intval and textval, become members of the comp_t structure, and the structure is specified in the FETCH command:EXEC SQL BEGIN DECLARE SECTION; typedef struct { int intval; varchar textval[33]; } comp_t; comp_t compval; EXEC SQL END DECLARE SECTION; /* Put each element of the composite type column in the SELECT list. */ EXEC SQL DECLARE cur1 CURSOR FOR SELECT (compval).intval, (compval).textval FROM t4; EXEC SQL OPEN cur1; EXEC SQL WHENEVER NOT FOUND DO BREAK; while (1) { /* Put all values in the SELECT list into one structure. */ EXEC SQL FETCH FROM cur1 INTO :compval; printf("intval=%d, textval=%s\n", compval.intval, compval.textval.arr); } EXEC SQL CLOSE cur1;
Although a structure is used in the FETCH command, the attribute names in the SELECT clause are specified one by one. This can be enhanced by using a * to ask for all attributes of the composite type value. For example:... EXEC SQL DECLARE cur1 CURSOR FOR SELECT (compval).* FROM t4; EXEC SQL OPEN cur1; EXEC SQL WHENEVER NOT FOUND DO BREAK; while (1) { /* Put all values in the SELECT list into one structure. */ EXEC SQL FETCH FROM cur1 INTO :compval; printf("intval=%d, textval=%s\n", compval.intval, compval.textval.arr); } ...
In this way, composite types can be mapped into structures, even though ECPG does not understand the composite type itself.
- User-defined base types
When ECPG uses host variables to store query results, only the data types provided by ECPG are supported. User-defined data types are not supported. Data types created using CREATE TYPE cannot be mapped using host variables.
However, you can use external string representations and host variables of the char[] or VARCHAR[] type to handle user-defined types.
The external string representation of that type is (%lf,%lf), which is defined in function complex_in(). The following example inserts complex type values (1,1) and (3,3) into columns a and b and then queries them from the table.EXEC SQL BEGIN DECLARE SECTION; varchar a[64]; varchar b[64]; EXEC SQL END DECLARE SECTION; EXEC SQL INSERT INTO test_complex VALUES ('(1,1)', '(3,3)'); EXEC SQL DECLARE cur1 CURSOR FOR SELECT a, b FROM test_complex; EXEC SQL OPEN cur1; EXEC SQL WHENEVER NOT FOUND DO BREAK; while (1) { EXEC SQL FETCH FROM cur1 INTO :a, :b; printf("a=%s, b=%s\n", a.arr, b.arr); } EXEC SQL CLOSE cur1;
Example output:a=(1,1), b=(3,3)
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot