2 34.4. Using Host Variables #
5 34.4.2. Declare Sections
6 34.4.3. Retrieving Query Results
8 34.4.5. Handling Nonprimitive SQL Data Types
11 In Section 34.3 you saw how you can execute SQL statements from an
12 embedded SQL program. Some of those statements only used fixed values
13 and did not provide a way to insert user-supplied values into
14 statements or have the program process the values returned by the
15 query. Those kinds of statements are not really useful in real
16 applications. This section explains in detail how you can pass data
17 between your C program and the embedded SQL statements using a simple
18 mechanism called host variables. In an embedded SQL program we consider
19 the SQL statements to be guests in the C program code which is the host
20 language. Therefore the variables of the C program are called host
23 Another way to exchange values between PostgreSQL backends and ECPG
24 applications is the use of SQL descriptors, described in Section 34.7.
28 Passing data between the C program and the SQL statements is
29 particularly simple in embedded SQL. Instead of having the program
30 paste the data into the statement, which entails various complications,
31 such as properly quoting the value, you can simply write the name of a
32 C variable into the SQL statement, prefixed by a colon. For example:
33 EXEC SQL INSERT INTO sometable VALUES (:v1, 'foo', :v2);
35 This statement refers to two C variables named v1 and v2 and also uses
36 a regular SQL string literal, to illustrate that you are not restricted
37 to use one kind of data or the other.
39 This style of inserting C variables in SQL statements works anywhere a
40 value expression is expected in an SQL statement.
42 34.4.2. Declare Sections #
44 To pass data from the program to the database, for example as
45 parameters in a query, or to pass data from the database back to the
46 program, the C variables that are intended to contain this data need to
47 be declared in specially marked sections, so the embedded SQL
48 preprocessor is made aware of them.
50 This section starts with:
51 EXEC SQL BEGIN DECLARE SECTION;
54 EXEC SQL END DECLARE SECTION;
56 Between those lines, there must be normal C variable declarations, such
59 char foo[16], bar[16];
61 As you can see, you can optionally assign an initial value to the
62 variable. The variable's scope is determined by the location of its
63 declaring section within the program. You can also declare variables
64 with the following syntax which implicitly creates a declare section:
67 You can have as many declare sections in a program as you like.
69 The declarations are also echoed to the output file as normal C
70 variables, so there's no need to declare them again. Variables that are
71 not intended to be used in SQL commands can be declared normally
72 outside these special sections.
74 The definition of a structure or union also must be listed inside a
75 DECLARE section. Otherwise the preprocessor cannot handle these types
76 since it does not know the definition.
78 34.4.3. Retrieving Query Results #
80 Now you should be able to pass data generated by your program into an
81 SQL command. But how do you retrieve the results of a query? For that
82 purpose, embedded SQL provides special variants of the usual commands
83 SELECT and FETCH. These commands have a special INTO clause that
84 specifies which host variables the retrieved values are to be stored
85 in. SELECT is used for a query that returns only single row, and FETCH
86 is used for a query that returns multiple rows, using a cursor.
91 * CREATE TABLE test1 (a int, b varchar(50));
94 EXEC SQL BEGIN DECLARE SECTION;
97 EXEC SQL END DECLARE SECTION;
101 EXEC SQL SELECT a, b INTO :v1, :v2 FROM test;
103 So the INTO clause appears between the select list and the FROM clause.
104 The number of elements in the select list and the list after INTO (also
105 called the target list) must be equal.
107 Here is an example using the command FETCH:
108 EXEC SQL BEGIN DECLARE SECTION;
111 EXEC SQL END DECLARE SECTION;
115 EXEC SQL DECLARE foo CURSOR FOR SELECT a, b FROM test;
122 EXEC SQL FETCH NEXT FROM foo INTO :v1, :v2;
126 Here the INTO clause appears after all the normal clauses.
128 34.4.4. Type Mapping #
130 When ECPG applications exchange values between the PostgreSQL server
131 and the C application, such as when retrieving query results from the
132 server or executing SQL statements with input parameters, the values
133 need to be converted between PostgreSQL data types and host language
134 variable types (C language data types, concretely). One of the main
135 points of ECPG is that it takes care of this automatically in most
138 In this respect, there are two kinds of data types: Some simple
139 PostgreSQL data types, such as integer and text, can be read and
140 written by the application directly. Other PostgreSQL data types, such
141 as timestamp and numeric can only be accessed through special library
142 functions; see Section 34.4.4.2.
144 Table 34.1 shows which PostgreSQL data types correspond to which C data
145 types. When you wish to send or receive a value of a given PostgreSQL
146 data type, you should declare a C variable of the corresponding C data
147 type in the declare section.
149 Table 34.1. Mapping Between PostgreSQL Data Types and C Variable Types
150 PostgreSQL data type Host variable type
157 double precision double
160 bigserial long long int
162 character(n), varchar(n), text char[n+1], VARCHAR[n+1]
163 name char[NAMEDATALEN]
164 timestamp timestamp^[a]
165 interval interval^[a]
168 bytea char *, bytea[n]
170 ^[a] This type can only be accessed through special library functions;
171 see Section 34.4.4.2.
173 ^[b] declared in ecpglib.h if not native
175 34.4.4.1. Handling Character Strings #
177 To handle SQL character string data types, such as varchar and text,
178 there are two possible ways to declare the host variables.
180 One way is using char[], an array of char, which is the most common way
181 to handle character data in C.
182 EXEC SQL BEGIN DECLARE SECTION;
184 EXEC SQL END DECLARE SECTION;
186 Note that you have to take care of the length yourself. If you use this
187 host variable as the target variable of a query which returns a string
188 with more than 49 characters, a buffer overflow occurs.
190 The other way is using the VARCHAR type, which is a special type
191 provided by ECPG. The definition on an array of type VARCHAR is
192 converted into a named struct for every variable. A declaration like:
196 struct varchar_var { int len; char arr[180]; } var;
198 The member arr hosts the string including a terminating zero byte.
199 Thus, to store a string in a VARCHAR host variable, the host variable
200 has to be declared with the length including the zero byte terminator.
201 The member len holds the length of the string stored in the arr without
202 the terminating zero byte. When a host variable is used as input for a
203 query, if strlen(arr) and len are different, the shorter one is used.
205 VARCHAR can be written in upper or lower case, but not in mixed case.
207 char and VARCHAR host variables can also hold values of other SQL
208 types, which will be stored in their string forms.
210 34.4.4.2. Accessing Special Data Types #
212 ECPG contains some special types that help you to interact easily with
213 some special data types from the PostgreSQL server. In particular, it
214 has implemented support for the numeric, decimal, date, timestamp, and
215 interval types. These data types cannot usefully be mapped to primitive
216 host variable types (such as int, long long int, or char[]), because
217 they have a complex internal structure. Applications deal with these
218 types by declaring host variables in special types and accessing them
219 using functions in the pgtypes library. The pgtypes library, described
220 in detail in Section 34.6 contains basic functions to deal with those
221 types, such that you do not need to send a query to the SQL server just
222 for adding an interval to a time stamp for example.
224 The follow subsections describe these special data types. For more
225 details about pgtypes library functions, see Section 34.6.
227 34.4.4.2.1. timestamp, date #
229 Here is a pattern for handling timestamp variables in the ECPG host
232 First, the program has to include the header file for the timestamp
234 #include <pgtypes_timestamp.h>
236 Next, declare a host variable as type timestamp in the declare section:
237 EXEC SQL BEGIN DECLARE SECTION;
239 EXEC SQL END DECLARE SECTION;
241 And after reading a value into the host variable, process it using
242 pgtypes library functions. In following example, the timestamp value is
243 converted into text (ASCII) form with the PGTYPEStimestamp_to_asc()
245 EXEC SQL SELECT now()::timestamp INTO :ts;
247 printf("ts = %s\n", PGTYPEStimestamp_to_asc(ts));
249 This example will show some result like following:
250 ts = 2010-06-27 18:03:56.949343
252 In addition, the DATE type can be handled in the same way. The program
253 has to include pgtypes_date.h, declare a host variable as the date type
254 and convert a DATE value into a text form using PGTYPESdate_to_asc()
255 function. For more details about the pgtypes library functions, see
258 34.4.4.2.2. interval #
260 The handling of the interval type is also similar to the timestamp and
261 date types. It is required, however, to allocate memory for an interval
262 type value explicitly. In other words, the memory space for the
263 variable has to be allocated in the heap memory, not in the stack
266 Here is an example program:
269 #include <pgtypes_interval.h>
274 EXEC SQL BEGIN DECLARE SECTION;
276 EXEC SQL END DECLARE SECTION;
278 EXEC SQL CONNECT TO testdb;
279 EXEC SQL SELECT pg_catalog.set_config('search_path', '', false); EXEC SQL CO
282 in = PGTYPESinterval_new();
283 EXEC SQL SELECT '1 min'::interval INTO :in;
284 printf("interval = %s\n", PGTYPESinterval_to_asc(in));
285 PGTYPESinterval_free(in);
288 EXEC SQL DISCONNECT ALL;
292 34.4.4.2.3. numeric, decimal #
294 The handling of the numeric and decimal types is similar to the
295 interval type: It requires defining a pointer, allocating some memory
296 space on the heap, and accessing the variable using the pgtypes library
297 functions. For more details about the pgtypes library functions, see
300 No functions are provided specifically for the decimal type. An
301 application has to convert it to a numeric variable using a pgtypes
302 library function to do further processing.
304 Here is an example program handling numeric and decimal type variables.
307 #include <pgtypes_numeric.h>
309 EXEC SQL WHENEVER SQLERROR STOP;
314 EXEC SQL BEGIN DECLARE SECTION;
318 EXEC SQL END DECLARE SECTION;
320 EXEC SQL CONNECT TO testdb;
321 EXEC SQL SELECT pg_catalog.set_config('search_path', '', false); EXEC SQL CO
324 num = PGTYPESnumeric_new();
325 dec = PGTYPESdecimal_new();
327 EXEC SQL SELECT 12.345::numeric(4,2), 23.456::decimal(4,2) INTO :num, :dec;
329 printf("numeric = %s\n", PGTYPESnumeric_to_asc(num, 0));
330 printf("numeric = %s\n", PGTYPESnumeric_to_asc(num, 1));
331 printf("numeric = %s\n", PGTYPESnumeric_to_asc(num, 2));
333 /* Convert decimal to numeric to show a decimal value. */
334 num2 = PGTYPESnumeric_new();
335 PGTYPESnumeric_from_decimal(dec, num2);
337 printf("decimal = %s\n", PGTYPESnumeric_to_asc(num2, 0));
338 printf("decimal = %s\n", PGTYPESnumeric_to_asc(num2, 1));
339 printf("decimal = %s\n", PGTYPESnumeric_to_asc(num2, 2));
341 PGTYPESnumeric_free(num2);
342 PGTYPESdecimal_free(dec);
343 PGTYPESnumeric_free(num);
346 EXEC SQL DISCONNECT ALL;
352 The handling of the bytea type is similar to that of VARCHAR. The
353 definition on an array of type bytea is converted into a named struct
354 for every variable. A declaration like:
358 struct bytea_var { int len; char arr[180]; } var;
360 The member arr hosts binary format data. It can also handle '\0' as
361 part of data, unlike VARCHAR. The data is converted from/to hex format
362 and sent/received by ecpglib.
366 bytea variable can be used only when bytea_output is set to hex.
368 34.4.4.3. Host Variables with Nonprimitive Types #
370 As a host variable you can also use arrays, typedefs, structs, and
375 There are two use cases for arrays as host variables. The first is a
376 way to store some text string in char[] or VARCHAR[], as explained in
377 Section 34.4.4.1. The second use case is to retrieve multiple rows from
378 a query result without using a cursor. Without an array, to process a
379 query result consisting of multiple rows, it is required to use a
380 cursor and the FETCH command. But with array host variables, multiple
381 rows can be received at once. The length of the array has to be defined
382 to be able to accommodate all rows, otherwise a buffer overflow will
385 Following example scans the pg_database system table and shows all OIDs
386 and names of the available databases:
390 EXEC SQL BEGIN DECLARE SECTION;
394 EXEC SQL END DECLARE SECTION;
396 memset(dbname, 0, sizeof(char)* 16 * 8);
397 memset(dbid, 0, sizeof(int) * 8);
399 EXEC SQL CONNECT TO testdb;
400 EXEC SQL SELECT pg_catalog.set_config('search_path', '', false); EXEC SQL CO
403 /* Retrieve multiple rows into arrays at once. */
404 EXEC SQL SELECT oid,datname INTO :dbid, :dbname FROM pg_database;
406 for (i = 0; i < 8; i++)
407 printf("oid=%d, dbname=%s\n", dbid[i], dbname[i]);
410 EXEC SQL DISCONNECT ALL;
414 This example shows following result. (The exact values depend on local
416 oid=1, dbname=template1
417 oid=11510, dbname=template0
418 oid=11511, dbname=postgres
419 oid=313780, dbname=testdb
424 34.4.4.3.2. Structures #
426 A structure whose member names match the column names of a query
427 result, can be used to retrieve multiple columns at once. The structure
428 enables handling multiple column values in a single host variable.
430 The following example retrieves OIDs, names, and sizes of the available
431 databases from the pg_database system table and using the
432 pg_database_size() function. In this example, a structure variable
433 dbinfo_t with members whose names match each column in the SELECT
434 result is used to retrieve one result row without putting multiple host
435 variables in the FETCH statement.
436 EXEC SQL BEGIN DECLARE SECTION;
445 EXEC SQL END DECLARE SECTION;
447 memset(&dbval, 0, sizeof(dbinfo_t));
449 EXEC SQL DECLARE cur1 CURSOR FOR SELECT oid, datname, pg_database_size(oid)
450 AS size FROM pg_database;
453 /* when end of result set reached, break out of while loop */
454 EXEC SQL WHENEVER NOT FOUND DO BREAK;
458 /* Fetch multiple columns into one structure. */
459 EXEC SQL FETCH FROM cur1 INTO :dbval;
461 /* Print members of the structure. */
462 printf("oid=%d, datname=%s, size=%lld\n", dbval.oid, dbval.datname, dbva
468 This example shows following result. (The exact values depend on local
470 oid=1, datname=template1, size=4324580
471 oid=11510, datname=template0, size=4243460
472 oid=11511, datname=postgres, size=4324580
473 oid=313780, datname=testdb, size=8183012
475 Structure host variables “absorb” as many columns as the structure as
476 fields. Additional columns can be assigned to other host variables. For
477 example, the above program could also be restructured like this, with
478 the size variable outside the structure:
479 EXEC SQL BEGIN DECLARE SECTION;
488 EXEC SQL END DECLARE SECTION;
490 memset(&dbval, 0, sizeof(dbinfo_t));
492 EXEC SQL DECLARE cur1 CURSOR FOR SELECT oid, datname, pg_database_size(oid)
493 AS size FROM pg_database;
496 /* when end of result set reached, break out of while loop */
497 EXEC SQL WHENEVER NOT FOUND DO BREAK;
501 /* Fetch multiple columns into one structure. */
502 EXEC SQL FETCH FROM cur1 INTO :dbval, :size;
504 /* Print members of the structure. */
505 printf("oid=%d, datname=%s, size=%lld\n", dbval.oid, dbval.datname, size
511 34.4.4.3.3. Typedefs #
513 Use the typedef keyword to map new types to already existing types.
514 EXEC SQL BEGIN DECLARE SECTION;
515 typedef char mychartype[40];
516 typedef long serial_t;
517 EXEC SQL END DECLARE SECTION;
519 Note that you could also use:
520 EXEC SQL TYPE serial_t IS long;
522 This declaration does not need to be part of a declare section; that
523 is, you can also write typedefs as normal C statements.
525 Any word you declare as a typedef cannot be used as an SQL keyword in
526 EXEC SQL commands later in the same program. For example, this won't
528 EXEC SQL BEGIN DECLARE SECTION;
530 EXEC SQL END DECLARE SECTION;
532 EXEC SQL START TRANSACTION;
534 ECPG will report a syntax error for START TRANSACTION, because it no
535 longer recognizes START as an SQL keyword, only as a typedef. (If you
536 have such a conflict, and renaming the typedef seems impractical, you
537 could write the SQL command using dynamic SQL.)
541 In PostgreSQL releases before v16, use of SQL keywords as typedef names
542 was likely to result in syntax errors associated with use of the
543 typedef itself, rather than use of the name as an SQL keyword. The new
544 behavior is less likely to cause problems when an existing ECPG
545 application is recompiled in a new PostgreSQL release with new
548 34.4.4.3.4. Pointers #
550 You can declare pointers to the most common types. Note however that
551 you cannot use pointers as target variables of queries without
552 auto-allocation. See Section 34.7 for more information on
555 EXEC SQL BEGIN DECLARE SECTION;
558 EXEC SQL END DECLARE SECTION;
560 34.4.5. Handling Nonprimitive SQL Data Types #
562 This section contains information on how to handle nonscalar and
563 user-defined SQL-level data types in ECPG applications. Note that this
564 is distinct from the handling of host variables of nonprimitive types,
565 described in the previous section.
569 Multi-dimensional SQL-level arrays are not directly supported in ECPG.
570 One-dimensional SQL-level arrays can be mapped into C array host
571 variables and vice-versa. However, when creating a statement ecpg does
572 not know the types of the columns, so that it cannot check if a C array
573 is input into a corresponding SQL-level array. When processing the
574 output of an SQL statement, ecpg has the necessary information and thus
575 checks if both are arrays.
577 If a query accesses elements of an array separately, then this avoids
578 the use of arrays in ECPG. Then, a host variable with a type that can
579 be mapped to the element type should be used. For example, if a column
580 type is array of integer, a host variable of type int can be used. Also
581 if the element type is varchar or text, a host variable of type char[]
582 or VARCHAR[] can be used.
584 Here is an example. Assume the following table:
589 testdb=> SELECT * FROM t3;
595 The following example program retrieves the 4th element of the array
596 and stores it into a host variable of type int:
597 EXEC SQL BEGIN DECLARE SECTION;
599 EXEC SQL END DECLARE SECTION;
601 EXEC SQL DECLARE cur1 CURSOR FOR SELECT ii[4] FROM t3;
604 EXEC SQL WHENEVER NOT FOUND DO BREAK;
608 EXEC SQL FETCH FROM cur1 INTO :ii ;
609 printf("ii=%d\n", ii);
614 This example shows the following result:
617 To map multiple array elements to the multiple elements in an array
618 type host variables each element of array column and each element of
619 the host variable array have to be managed separately, for example:
620 EXEC SQL BEGIN DECLARE SECTION;
622 EXEC SQL END DECLARE SECTION;
624 EXEC SQL DECLARE cur1 CURSOR FOR SELECT ii[1], ii[2], ii[3], ii[4] FROM t3;
627 EXEC SQL WHENEVER NOT FOUND DO BREAK;
631 EXEC SQL FETCH FROM cur1 INTO :ii_a[0], :ii_a[1], :ii_a[2], :ii_a[3];
636 EXEC SQL BEGIN DECLARE SECTION;
638 EXEC SQL END DECLARE SECTION;
640 EXEC SQL DECLARE cur1 CURSOR FOR SELECT ii FROM t3;
643 EXEC SQL WHENEVER NOT FOUND DO BREAK;
648 EXEC SQL FETCH FROM cur1 INTO :ii_a;
652 would not work correctly in this case, because you cannot map an array
653 type column to an array host variable directly.
655 Another workaround is to store arrays in their external string
656 representation in host variables of type char[] or VARCHAR[]. For more
657 details about this representation, see Section 8.15.2. Note that this
658 means that the array cannot be accessed naturally as an array in the
659 host program (without further processing that parses the text
662 34.4.5.2. Composite Types #
664 Composite types are not directly supported in ECPG, but an easy
665 workaround is possible. The available workarounds are similar to the
666 ones described for arrays above: Either access each attribute
667 separately or use the external string representation.
669 For the following examples, assume the following type and table:
670 CREATE TYPE comp_t AS (intval integer, textval varchar(32));
671 CREATE TABLE t4 (compval comp_t);
672 INSERT INTO t4 VALUES ( (256, 'PostgreSQL') );
674 The most obvious solution is to access each attribute separately. The
675 following program retrieves data from the example table by selecting
676 each attribute of the type comp_t separately:
677 EXEC SQL BEGIN DECLARE SECTION;
680 EXEC SQL END DECLARE SECTION;
682 /* Put each element of the composite type column in the SELECT list. */
683 EXEC SQL DECLARE cur1 CURSOR FOR SELECT (compval).intval, (compval).textval FROM
687 EXEC SQL WHENEVER NOT FOUND DO BREAK;
691 /* Fetch each element of the composite type column into host variables. */
692 EXEC SQL FETCH FROM cur1 INTO :intval, :textval;
694 printf("intval=%d, textval=%s\n", intval, textval.arr);
699 To enhance this example, the host variables to store values in the
700 FETCH command can be gathered into one structure. For more details
701 about the host variable in the structure form, see Section 34.4.4.3.2.
702 To switch to the structure, the example can be modified as below. The
703 two host variables, intval and textval, become members of the comp_t
704 structure, and the structure is specified on the FETCH command.
705 EXEC SQL BEGIN DECLARE SECTION;
713 EXEC SQL END DECLARE SECTION;
715 /* Put each element of the composite type column in the SELECT list. */
716 EXEC SQL DECLARE cur1 CURSOR FOR SELECT (compval).intval, (compval).textval FROM
720 EXEC SQL WHENEVER NOT FOUND DO BREAK;
724 /* Put all values in the SELECT list into one structure. */
725 EXEC SQL FETCH FROM cur1 INTO :compval;
727 printf("intval=%d, textval=%s\n", compval.intval, compval.textval.arr);
732 Although a structure is used in the FETCH command, the attribute names
733 in the SELECT clause are specified one by one. This can be enhanced by
734 using a * to ask for all attributes of the composite type value.
736 EXEC SQL DECLARE cur1 CURSOR FOR SELECT (compval).* FROM t4;
739 EXEC SQL WHENEVER NOT FOUND DO BREAK;
743 /* Put all values in the SELECT list into one structure. */
744 EXEC SQL FETCH FROM cur1 INTO :compval;
746 printf("intval=%d, textval=%s\n", compval.intval, compval.textval.arr);
750 This way, composite types can be mapped into structures almost
751 seamlessly, even though ECPG does not understand the composite type
754 Finally, it is also possible to store composite type values in their
755 external string representation in host variables of type char[] or
756 VARCHAR[]. But that way, it is not easily possible to access the fields
757 of the value from the host program.
759 34.4.5.3. User-Defined Base Types #
761 New user-defined base types are not directly supported by ECPG. You can
762 use the external string representation and host variables of type
763 char[] or VARCHAR[], and this solution is indeed appropriate and
764 sufficient for many types.
766 Here is an example using the data type complex from the example in
767 Section 36.13. The external string representation of that type is
768 (%f,%f), which is defined in the functions complex_in() and
769 complex_out() functions in Section 36.13. The following example inserts
770 the complex type values (1,1) and (3,3) into the columns a and b, and
771 select them from the table after that.
772 EXEC SQL BEGIN DECLARE SECTION;
775 EXEC SQL END DECLARE SECTION;
777 EXEC SQL INSERT INTO test_complex VALUES ('(1,1)', '(3,3)');
779 EXEC SQL DECLARE cur1 CURSOR FOR SELECT a, b FROM test_complex;
782 EXEC SQL WHENEVER NOT FOUND DO BREAK;
786 EXEC SQL FETCH FROM cur1 INTO :a, :b;
787 printf("a=%s, b=%s\n", a.arr, b.arr);
792 This example shows following result:
795 Another workaround is avoiding the direct use of the user-defined types
796 in ECPG and instead create a function or cast that converts between the
797 user-defined type and a primitive type that ECPG can handle. Note,
798 however, that type casts, especially implicit ones, should be
799 introduced into the type system very carefully.
802 CREATE FUNCTION create_complex(r double, i double) RETURNS complex
805 AS $$ SELECT $1 * complex '(1,0')' + $2 * complex '(0,1)' $$;
807 After this definition, the following
808 EXEC SQL BEGIN DECLARE SECTION;
810 EXEC SQL END DECLARE SECTION;
817 EXEC SQL INSERT INTO test_complex VALUES (create_complex(:a, :b), create_complex
820 has the same effect as
821 EXEC SQL INSERT INTO test_complex VALUES ('(1,2)', '(3,4)');
825 The examples above do not handle null values. In fact, the retrieval
826 examples will raise an error if they fetch a null value from the
827 database. To be able to pass null values to the database or retrieve
828 null values from the database, you need to append a second host
829 variable specification to each host variable that contains data. This
830 second host variable is called the indicator and contains a flag that
831 tells whether the datum is null, in which case the value of the real
832 host variable is ignored. Here is an example that handles the retrieval
833 of null values correctly:
834 EXEC SQL BEGIN DECLARE SECTION;
837 EXEC SQL END DECLARE SECTION:
841 EXEC SQL SELECT b INTO :val :val_ind FROM test1;
843 The indicator variable val_ind will be zero if the value was not null,
844 and it will be negative if the value was null. (See Section 34.16 to
845 enable Oracle-specific behavior.)
847 The indicator has another function: if the indicator value is positive,
848 it means that the value is not null, but it was truncated when it was
849 stored in the host variable.
851 If the argument -r no_indicator is passed to the preprocessor ecpg, it
852 works in “no-indicator” mode. In no-indicator mode, if no indicator
853 variable is specified, null values are signaled (on input and output)
854 for character string types as empty string and for integer types as the
855 lowest possible value for type (for example, INT_MIN for int).