diff --git a/doc/src/sgml/ecpg.sgml b/doc/src/sgml/ecpg.sgml index 645a6faafae..835d35ab991 100644 --- a/doc/src/sgml/ecpg.sgml +++ b/doc/src/sgml/ecpg.sgml @@ -13,7 +13,7 @@ Linus Tolke (linus@epact.se) and Michael Meskes (meskes@postgresql.org). Originally it was written to work with C. It also works with C++, but - it does not recognize all C++ constructs yet. + it does not recognize all C++ constructs yet. @@ -28,10 +28,13 @@ An embedded SQL program consists of code written in an ordinary programming language, in this case C, mixed with SQL commands in - specially marked sections. To build the program, the source code + specially marked sections. To build the program, the source code (*.pgc) is first passed through the embedded SQL preprocessor, which converts it - to an ordinary C program, and afterwards it can be processed by a C - compiler. + to an ordinary C program (*.c), and afterwards it can be processed by a C + compiler. (For details about the compiling and linking see ). + Converted ECPG applications call functions in the libpq library + through the embedded SQL library (ecpglib), and communicate with + the PostgreSQL server using the normal frontend-backend protocol. @@ -71,7 +74,15 @@ EXEC SQL ...; - Connecting to the Database Server + Managing Database Connections + + + This section describes how to open, close, and switch database + connections. + + + + Connecting to the database server One connects to a database using the following statement: @@ -200,10 +211,91 @@ EXEC SQL CONNECT TO :target USER :user; example above to encapsulate the connection target string somewhere. - + - - Closing a Connection + + Choosing a connection + + + SQL statements in embedded SQL programs are by default executed on + the current connection, that is, the most recently opened one. If + an application needs to manage multiple connections, then there are + two ways to handle this. + + + + The first option is to explicitly choose a connection for each SQL + statement, for example: + +EXEC SQL AT connection-name SELECT ...; + + This option is particularly suitable if the application needs to + use several connections in mixed order. + + + + If your application uses multiple threads of execution, they cannot share a + connection concurrently. You must either explicitly control access to the connection + (using mutexes) or use a connection for each thread. If each thread uses its own connection, + you will need to use the AT clause to specify which connection the thread will use. + + + + The second option is to execute a statement to switch the current + connection. That statement is: + +EXEC SQL SET CONNECTION connection-name; + + This option is particularly convenient if many statements are to be + executed on the same connection. It is not thread-aware. + + + + Here is an example program managing multiple database connections: + + +EXEC SQL BEGIN DECLARE SECTION; + char dbname[1024]; +EXEC SQL END DECLARE SECTION; + +int +main() +{ + EXEC SQL CONNECT TO testdb1 AS con1 USER testuser; + EXEC SQL CONNECT TO testdb2 AS con2 USER testuser; + EXEC SQL CONNECT TO testdb3 AS con3 USER testuser; + + /* This query would be executed in the last opened database "testdb3". */ + EXEC SQL SELECT current_database() INTO :dbname; + printf("current=%s (should be testdb3)\n", dbname); + + /* Using "AT" to run a query in "testdb2" */ + EXEC SQL AT con2 SELECT current_database() INTO :dbname; + printf("current=%s (should be testdb2)\n", dbname); + + /* Switch the current connection to "testdb1". */ + EXEC SQL SET CONNECTION con1; + + EXEC SQL SELECT current_database() INTO :dbname; + printf("current=%s (should be testdb1)\n", dbname); + + EXEC SQL DISCONNECT ALL; + return 0; +} +]]> + + This example would produce this output: + +current=testdb3 (should be testdb3) +current=testdb2 (should be testdb2) +current=testdb1 (should be testdb1) + + + + + + Closing a connection To close a connection, use the following statement: @@ -247,6 +339,8 @@ EXEC SQL DISCONNECT connection; It is good style that an application always explicitly disconnect from every connection it opened. + + @@ -257,6 +351,9 @@ EXEC SQL DISCONNECT connection; Below are some examples of how to do that. + + Executing SQL statements + Creating a table: @@ -282,6 +379,26 @@ EXEC SQL COMMIT; + + Updates: + +EXEC SQL UPDATE foo + SET ascii = 'foobar' + WHERE number = 9999; +EXEC SQL COMMIT; + + + + + SELECT statements that return a single result + row can also be executed using + EXEC SQL directly. To handle result sets with + multiple rows, an application has to use a cursor; + see below. (As a special case, an + application can fetch multiple rows at once into an array host + variable; see .) + + Single-row select: @@ -289,6 +406,33 @@ EXEC SQL SELECT foo INTO :FooBar FROM table1 WHERE ascii = 'doodad'; + + Also, a configuration parameter can be retreived with the + SHOW command: + +EXEC SQL SHOW search_path INTO :var; + + + + + The tokens of the form + :something are + host variables, that is, they refer to + variables in the C program. They are explained in . + + + + + Using cursors + + + To retrieve a result set holding multiple rows, an application has + to declare a cursor and fetch each row from the cursor. The steps + to use a cursor are the following: declare a cursor, open it, fetch + a row from the cursor, repeat, and finally close it. + + Select using cursors: @@ -304,72 +448,150 @@ EXEC SQL COMMIT; - Updates: - -EXEC SQL UPDATE foo - SET ascii = 'foobar' - WHERE number = 9999; -EXEC SQL COMMIT; - + For more details about declaration of the cursor, + see , and + see for FETCH command + details. - - The tokens of the form - :something are - host variables, that is, they refer to - variables in the C program. They are explained in . - + + + The ECPG DECLARE command does not actually + cause a statement to be sent to the PostgreSQL backend. The + cursor is opened in the backend (using the + backend's DECLARE command) at the point when + the OPEN command is executed. + + + + + + Managing transactions In the default mode, statements are committed only when EXEC SQL COMMIT is issued. The embedded SQL interface also supports autocommit of transactions (similar to - libpq behavior) via the command-line - option to ecpg (see below) or via the EXEC SQL - SET AUTOCOMMIT TO ON statement. In autocommit mode, each - command is automatically committed unless it is inside an explicit - transaction block. This mode can be explicitly turned off using - EXEC SQL SET AUTOCOMMIT TO OFF. - - - - - Choosing a Connection - - - The SQL statements shown in the previous section are executed on - the current connection, that is, the most recently opened one. If - an application needs to manage multiple connections, then there are - two ways to handle this. + libpq behavior) via the + command-line option to ecpg (see ) or via the EXEC SQL SET AUTOCOMMIT TO + ON statement. In autocommit mode, each command is + automatically committed unless it is inside an explicit transaction + block. This mode can be explicitly turned off using EXEC + SQL SET AUTOCOMMIT TO OFF. - - The first option is to explicitly choose a connection for each SQL - statement, for example: + + The following transaction management commands are available: + + + + EXEC SQL COMMIT + + + Commit an in-progress transaction. + + + + + + EXEC SQL ROLLBACK + + + Roll back an in-progress transaction. + + + + + + EXEC SQL SET AUTOCOMMIT TO ON + + + Enable autocommit mode. + + + + + + SET AUTOCOMMIT TO OFF + + + Disable autocommit mode. This is the default. + + + + + + + + + Prepared statements + + + When the values to be passed to an SQL statement are not known at + compile time, or the same statement is going to be used many + times, then prepared statements can be useful. + + + + The statement is prepared using the + command PREPARE. For the values that are not + known yet, use the + placeholder ?: -EXEC SQL AT connection-name SELECT ...; +EXEC SQL PREPARE stmt1 FROM "SELECT oid, datname FROM pg_database WHERE oid = ?"; - This option is particularly suitable if the application needs to - use several connections in mixed order. - + - - If your application uses multiple threads of execution, they cannot share a - connection concurrently. You must either explicitly control access to the connection - (using mutexes) or use a connection for each thread. If each thread uses its own connection, - you will need to use the AT clause to specify which connection the thread will use. - - - - The second option is to execute a statement to switch the current - connection. That statement is: + + If a statement returns a single row, the application can + call EXECUTE after + PREPARE to execute the statement, supplying the + actual values for the placeholders with a USING + clause: -EXEC SQL SET CONNECTION connection-name; +EXEC SQL EXECUTE stmt1 INTO :dboid, :dbname USING 1; - This option is particularly convenient if many statements are to be - executed on the same connection. It is not thread-aware. - + + + + If a statement return multiple rows, the application can use a + cursor declared based on the prepared statement. To bind input + parameters, the cursor must be opened with + a USING clause: + +EXEC SQL PREPARE stmt1 FROM "SELECT oid,datname FROM pg_database WHERE oid > ?"; +EXEC SQL DECLARE foo_bar CURSOR FOR stmt1; + +/* when end of result set reached, break out of while loop */ +EXEC SQL WHENEVER NOT FOUND DO BREAK; + +EXEC SQL OPEN foo_bar USING 100; +... +while (1) +{ + EXEC SQL FETCH NEXT FROM foo_bar INTO :dboid, :dbname; + ... +} +EXEC SQL CLOSE foo_bar; + + + + + When you don't need the prepared statement anymore, you should + deallocate it: + +EXEC SQL DEALLOCATE PREPARE name; + + + + + For more details about PREPARE, + see . Also + see for more details about using + placeholders and input parameters. + + @@ -391,7 +613,13 @@ EXEC SQL SET CONNECTION connection-name; variables. - + + Another way to exchange values between PostgreSQL backends and ECPG + applications is the use of SQL descriptors, described + in . + + + Overview @@ -416,7 +644,7 @@ EXEC SQL INSERT INTO sometable VALUES (:v1, 'foo', :v2); - + Declare Sections @@ -467,107 +695,8 @@ EXEC SQL int i = 4; - - Different types of host variables - - As a host variable you can also use arrays, typedefs, structs and - pointers. Moreover there are special types of host variables that exist - only in ECPG. - - - - A few examples on host variables: - - - Arrays - - - One of the most common uses of an array declaration is probably the - allocation of a char array as in: - -EXEC SQL BEGIN DECLARE SECTION; - char str[50]; -EXEC SQL END DECLARE SECTION; - - Note that you have to take care of the length for yourself. If you use - this host variable as the target variable of a query which returns a - string with more than 49 characters, a buffer overflow occurs. - - - - - - Typedefs - - - Use the typedef keyword to map new types to already - existing types. - -EXEC SQL BEGIN DECLARE SECTION; - typedef char mychartype[40]; - typedef long serial_t; -EXEC SQL END DECLARE SECTION; - - Note that you could also use: - -EXEC SQL TYPE serial_t IS long; - - This declaration does not need to be part of a declare section. - - - - - - Pointers - - - You can declare pointers to the most common types. Note however that - you cannot use pointers as target variables of queries without - auto-allocation. See for more - information on auto-allocation. - - -EXEC SQL BEGIN DECLARE SECTION; - int *intp; - char **charp; -EXEC SQL END DECLARE SECTION; - - - - - - Special types of variables - - - ECPG contains some special types that help you to interact easily with - data from the SQL server. For example it has implemented support for - the varchar, numeric, date, timestamp, and interval types. - contains basic functions to deal with - those types, such that you do not need to send a query to the SQL - server just for adding an interval to a timestamp for example. - - - The special type VARCHAR - is converted into a named struct for every variable. A - declaration like: - -VARCHAR var[180]; - - is converted into: - -struct varchar_var { int len; char arr[180]; } var; - - This structure is suitable for interfacing with SQL datums of type - varchar. - - - - - - - - - <command>SELECT INTO</command> and <command>FETCH INTO</command> + + Retrieving query results Now you should be able to pass data generated by your program into @@ -577,6 +706,9 @@ struct varchar_var { int len; char arr[180]; } var; FETCH. These commands have a special INTO clause that specifies which host variables the retrieved values are to be stored in. + SELECT is used for a query that returns only + single row, and FETCH is used for a query that + returns multiple rows, using a cursor. @@ -617,7 +749,8 @@ EXEC SQL DECLARE foo CURSOR FOR SELECT a, b FROM test; ... -do { +do +{ ... EXEC SQL FETCH NEXT FROM foo INTO :v1, :v2; ... @@ -634,7 +767,951 @@ do { - + + Type mapping + + + When ECPG applications exchange values between the PostgreSQL + server and the C application, such as when retrieving query + results from the server or executing SQL statements with input + parameters, the values need to be converted between PostgreSQL + data types and host language variable types (C language data + types, concretely). One of the main points of ECPG is that it + takes care of this automatically in most cases. + + + + In this respect, there are two kinds of data types: Some simple + PostgreSQL data types, such as integer + and text, can be read and written by the application + directly. Other PostgreSQL data types, such + as timestamp and numeric can only be + accessed through special library functions; see + . + + + + shows which PostgreSQL + data types correspond to which C data types. When you wish to + send or receive a value of a given PostgreSQL data type, you + should declare a C variable of the corresponding C data type in + the declare section. + + + + Mapping between PostgreSQL data types and C variable types + + + + PostgreSQL data type + Host variable type + + + + + + smallint + short + + + + integer + int + + + + bigint + long long int + + + + decimal + decimalThis type can only be accessed through special library functions; see . + + + + numeric + numeric + + + + real + float + + + + double precision + double + + + + serial + int + + + + bigserial + long long int + + + + oid + unsigned int + + + + character(n), varchar(n), text + char[n+1], VARCHAR[n+1]declared in ecpglib.h + + + + name + char[NAMEDATALEN] + + + + timestamp + timestamp + + + + interval + interval + + + + date + date + + + + boolean + booldeclared in ecpglib.h if not native + + + +
+ + + Handling character strings + + + To handle SQL character string data types, such + as varchar and text, there are two + possible ways to declare the host variables. + + + + One way is using char[], an array + of char, which is the most common way to handle + character data in C. + +EXEC SQL BEGIN DECLARE SECTION; + char str[50]; +EXEC SQL END DECLARE SECTION; + + Note that you have to take care of the length yourself. If you + use this host variable as the target variable of a query which + returns a string with more than 49 characters, a buffer overflow + occurs. + + + + The other way is using the VARCHAR type, which is a + special type provided by ECPG. The definition on an array of + type VARCHAR is converted into a + named struct for every variable. A declaration like: + +VARCHAR var[180]; + + is converted into: + +struct varchar_var { int len; char arr[180]; } var; + + The member arr hosts the string + including a terminating zero byte. Thus, to store a string in + a VARCHAR host variable, the host variable has to be + declared with the length including the zero byte terminator. The + member len holds the length of the + string stored in the arr without the + terminating zero byte. When a host variable is used as input for + a query, if strlen(arr) + and len are different, the shorter one + is used. + + + + Two or more VARCHAR host variables cannot be defined + in single line statement. The following code will confuse + the ecpg preprocessor: + +VARCHAR v1[128], v2[128]; /* WRONG */ + + Two variables should be defined in separate statements like this: + +VARCHAR v1[128]; +VARCHAR v2[128]; + + + + + VARCHAR can be written in upper or lower case, but + not in mixed case. + + + + char and VARCHAR host variables can + also hold values of other SQL types, which will be stored in + their string forms. + + + + + Accessing special data types + + + ECPG contains some special types that help you to interact easily + with some special data types from the PostgreSQL server. In + particular, it has implemented support for the + numeric, decimal, date, timestamp, + and interval types. These data types cannot usefully be + mapped to primitive host variable types (such + as int, long long int, + or char[]), because they have a complex internal + structure. Applications deal with these types by declaring host + variables in special types and accessing them using functions in + the pgtypes library. The pgtypes library, described in detail + in contains basic functions to deal + with those types, such that you do not need to send a query to + the SQL server just for adding an interval to a timestamp for + example. + + + + The follow subsections describe these special data types. For + more details about pgtypes library functions, + see . + + + + timestamp, date + + + Here is a pattern for handling timestamp variables + in the ECPG host application. + + + + First, the program has to include the header file for the + timestamp type: + +#include <pgtypes_timestamp.h> + + + + + Next, declare a host variable as type timestamp in + the declare section: + +EXEC SQL BEGIN DECLARE SECTION; +timestamp ts; +EXEC SQL END DECLARE SECTION; + + + + + And after reading a value into the host variable, process it + using pgtypes library functions. In following example, the + timestamp value is converted into text (ASCII) form + with the PGTYPEStimestamp_to_asc() + function: + +EXEC SQL SELECT now()::timestamp INTO :ts; + +printf("ts = %s\n", PGTYPEStimestamp_to_asc(ts)); + + This example will show some result like following: + +ts = 2010-06-27 18:03:56.949343 + + + + + In addition, the DATE type can be handled in the same way. The + program has to include pg_types_date.h, declare a host variable + as the date type and convert a DATE value into a text form using + PGTYPESdate_to_asc() function. For more details about the + pgtypes library functions, see . + + + + + interval + + + The handling of the interval type is also similar + to the timestamp and date types. It + is required, however, to allocate memory for + an interval type value explicitly. In other words, + the memory space for the variable has to be allocated in the + heap memory, not in the stack memory. + + + + Here is an example program: + +#include <stdio.h> +#include <stdlib.h> +#include <pgtypes_interval.h> + +int +main(void) +{ +EXEC SQL BEGIN DECLARE SECTION; + interval *in; +EXEC SQL END DECLARE SECTION; + + EXEC SQL CONNECT TO testdb; + + in = PGTYPESinterval_new(); + EXEC SQL SELECT '1 min'::interval INTO :in; + printf("interval = %s\n", PGTYPESinterval_to_asc(in)); + PGTYPESinterval_free(in); + + EXEC SQL COMMIT; + EXEC SQL DISCONNECT ALL; + return 0; +} + + + + + + numeric, decimal + + + The handling of the numeric + and decimal types is similar to the + interval type: It requires defining a pointer, + allocating some memory space on the heap, and accessing the + variable using the pgtypes library functions. For more details + about the pgtypes library functions, + see . + + + + No functions are provided specifically for + the decimal type. An application has to convert it + to a numeric variable using a pgtypes library + function to do further processing. + + + + Here is an example program handling numeric + and decimal type variables. + +#include <stdio.h> +#include <stdlib.h> +#include <pgtypes_numeric.h> + +EXEC SQL WHENEVER SQLERROR STOP; + +int +main(void) +{ +EXEC SQL BEGIN DECLARE SECTION; + numeric *num; + numeric *num2; + decimal *dec; +EXEC SQL END DECLARE SECTION; + + EXEC SQL CONNECT TO testdb; + + num = PGTYPESnumeric_new(); + dec = PGTYPESdecimal_new(); + + EXEC SQL SELECT 12.345::numeric(4,2), 23.456::decimal(4,2) INTO :num, :dec; + + printf("numeric = %s\n", PGTYPESnumeric_to_asc(num, 0)); + printf("numeric = %s\n", PGTYPESnumeric_to_asc(num, 1)); + printf("numeric = %s\n", PGTYPESnumeric_to_asc(num, 2)); + + /* Convert decimal to numeric to show a decimal value. */ + num2 = PGTYPESnumeric_new(); + PGTYPESnumeric_from_decimal(dec, num2); + + printf("decimal = %s\n", PGTYPESnumeric_to_asc(num2, 0)); + printf("decimal = %s\n", PGTYPESnumeric_to_asc(num2, 1)); + printf("decimal = %s\n", PGTYPESnumeric_to_asc(num2, 2)); + + PGTYPESnumeric_free(num2); + PGTYPESdecimal_free(dec); + PGTYPESnumeric_free(num); + + EXEC SQL COMMIT; + EXEC SQL DISCONNECT ALL; + return 0; +} + + + + + + + Host variables with nonprimitive types + + + As a host variable you can also use arrays, typedefs, structs, and + pointers. + + + + Arrays + + + There are two use cases for arrays as host variables. The first + is a way to store some text string in char[] + or VARCHAR[], as + explained . The second use case is to + retreive multiple rows from a query result without using a + cursor. Without an array, to process a query result consisting + of multiple rows, it is required to use a cursor and + the FETCH command. But with array host + variables, multiple rows can be received at once. The length of + the array has to be defined to be able to accomodate all rows, + otherwise a buffer overflow will likely occur. + + + + Following example scans the pg_database + system table and shows all OIDs and names of the available + databases: + +int +main(void) +{ +EXEC SQL BEGIN DECLARE SECTION; + int dbid[8]; + char dbname[8][16]; + int i; +EXEC SQL END DECLARE SECTION; + + memset(dbname, 0, sizeof(char)* 16 * 8); + memset(dbid, 0, sizeof(int) * 8); + + EXEC SQL CONNECT TO testdb; + + /* Retrieve multiple rows into arrays at once. */ + EXEC SQL SELECT oid,datname INTO :dbid, :dbname FROM pg_database; + + for (i = 0; i < 8; i++) + printf("oid=%d, dbname=%s\n", dbid[i], dbname[i]); + + EXEC SQL COMMIT; + EXEC SQL DISCONNECT ALL; + return 0; +} + + + This example shows following result. (The exact values depend on + local circumstances.) + +oid=1, dbname=template1 +oid=11510, dbname=template0 +oid=11511, dbname=postgres +oid=313780, dbname=testdb +oid=0, dbname= +oid=0, dbname= +oid=0, dbname= + + + + + + Structures + + + A structure whose member names match the column names of a query + result, can be used to retrieve multiple columns at once. The + structure enables handling multiple column values in a single + host variable. + + + + The following example retrieves OIDs, names, and sizes of the + avilable databases from the pg_database + system table and using + the pg_database_size() function. In this + example, a structure variable dbinfo_t with + members whose names match each column in + the SELECT result is used to retrieve one + result row without putting multiple host variables in + the FETCH statement. + +EXEC SQL BEGIN DECLARE SECTION; + typedef struct + { + int oid; + char datname[65]; + long long int size; + } dbinfo_t; + + dbinfo_t dbval; +EXEC SQL END DECLARE SECTION; + + memset(&dbval, 0, sizeof(dbinfo_t)); + + EXEC SQL DECLARE cur1 CURSOR FOR SELECT oid, datname, pg_database_size(oid) AS size FROM pg_database; + EXEC SQL OPEN cur1; + + /* when end of result set reached, break out of while loop */ + EXEC SQL WHENEVER NOT FOUND DO BREAK; + + while (1) + { + /* Fetch multiple columns into one structure. */ + EXEC SQL FETCH FROM cur1 INTO :dbval; + + /* Print members of the structure. */ + printf("oid=%d, datname=%s, size=%lld\n", dbval.oid, dbval.datname, dbval.size); + } + + EXEC SQL CLOSE cur1; + + + + + This example shows following result. (The exact values depend on + local circumstances.) + +oid=1, datname=template1, size=4324580 +oid=11510, datname=template0, size=4243460 +oid=11511, datname=postgres, size=4324580 +oid=313780, datname=testdb, size=8183012 + + + + + Structure host variables absorb as many columns + as the structure as fields. Additional columns can be assigned + to other host variables. For example, the above program could + also be restructured like this, with the size + variable outside the structure: + +EXEC SQL BEGIN DECLARE SECTION; + typedef struct + { + int oid; + char datname[65]; + } dbinfo_t; + + dbinfo_t dbval; + long long int size; +EXEC SQL END DECLARE SECTION; + + memset(&dbval, 0, sizeof(dbinfo_t)); + + EXEC SQL DECLARE cur1 CURSOR FOR SELECT oid, datname, pg_database_size(oid) AS size FROM pg_database; + EXEC SQL OPEN cur1; + + /* when end of result set reached, break out of while loop */ + EXEC SQL WHENEVER NOT FOUND DO BREAK; + + while (1) + { + /* Fetch multiple columns into one structure. */ + EXEC SQL FETCH FROM cur1 INTO :dbval, :size; + + /* Print members of the structure. */ + printf("oid=%d, datname=%s, size=%lld\n", dbval.oid, dbval.datname, size); + } + + EXEC SQL CLOSE cur1; + + + + + + Typedefs + + + Use the typedef keyword to map new types to already + existing types. + +EXEC SQL BEGIN DECLARE SECTION; + typedef char mychartype[40]; + typedef long serial_t; +EXEC SQL END DECLARE SECTION; + + Note that you could also use: + +EXEC SQL TYPE serial_t IS long; + + This declaration does not need to be part of a declare section. + + + + + Pointers + + + You can declare pointers to the most common types. Note however + that you cannot use pointers as target variables of queries + without auto-allocation. See + for more information on auto-allocation. + + + + +EXEC SQL BEGIN DECLARE SECTION; + int *intp; + char **charp; +EXEC SQL END DECLARE SECTION; + + + + +
+ + + Handling nonprimitive SQL data types + + + This section contains information on how to handle nonscalar and + user-defined SQL-level data types in ECPG applications. Note that + this is distinct from the handling of host variables of + nonprimitive types, described in the previous section. + + + + Arrays + + + SQL-level arrays are not directly supported in ECPG. It is not + possible to simply map an SQL array into a C array host variable. + This will result in undefined behavior. Some workarounds exist, + however. + + + + If a query accesses elements of an array + separately, then this avoids the use of arrays in ECPG. Then, 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. + + + + Here is an example. Assume the following table: + +CREATE TABLE t3 ( + ii integer[] +); + +testdb=> SELECT * FROM t3; + ii +------------- + {1,2,3,4,5} +(1 row) + + + The following example program retrieves the 4th element of the + array and stores it into a host variable of + type int: + +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; + + + This example shows the following result: + +ii=4 + + + + + To map multiple array elements to the multiple elements in an + array type host variables each element of array column and each + element of the host variable array have to 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 again that + +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) +{ + /* WRONG */ + EXEC SQL FETCH FROM cur1 INTO :ii_a; + ... +} + + would not work correctly in this case, because you cannot map an + array type column to an array host variable directly. + + + + Another workaround is to store arrays in their external string + representation in host variables of type char[] + or VARCHAR[]. For more details about this + representation, see . Note that + this means that the array cannot be accessed naturally as an + array in the host program (without further processing that parses + the text representation). + + + + + Composite types + + + Composite types are not directly supported in ECPG, but an easy workaround is possible. + The + available workarounds are similar to the ones described for + arrays above: Either access each attribute separately or use the + external string representation. + + + + For the following examples, assume the following type and table: + +CREATE TYPE comp_t AS (intval integer, textval varchar(32)); +CREATE TABLE t4 (compval comp_t); +INSERT INTO t4 VALUES ( (256, 'PostgreSQL') ); + + + The most obvious solution is to access each attribute separately. + The following program retrieves data from the example table by + selecting each attribute of the type comp_t + 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; + + + + + To enhance this example, the host variables to store values in + the FETCH command can be gathered into one + structure. For more details about the host variable in the + structure form, see . + To switch to the structure, the example can be modified as below. + The two host variables, intval + and textval, become members of + the comp_t structure, and the structure + is specified on 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. + +... +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); +} +... + + This way, composite types can be mapped into structures almost + seamlessly, even though ECPG does not understand the composite + type itself. + + + + Finally, it is also possible to store composite type values in + their external string representation in host variables of + type char[] or VARCHAR[]. But that + way, it is not easily possible to access the fields of the value + from the host program. + + + + + User-defined base types + + + New user-defined base types are not directly supported by ECPG. + You can use the external string representation and host variables + of type char[] or VARCHAR[], and this + solution is indeed appropriate and sufficient for many types. + + + + Here is an example using the data type complex from + the example in . The external string + representation of that type is (%lf,%lf), + which is defined in the + functions complex_in() + and complex_out() functions + in . The following example inserts the + complex type values (1,1) + and (3,3) into the + columns a and b, and select + them from the table after that. + + +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; + + + This example shows following result: + +a=(1,1), b=(3,3) + + + + + Another workaround is avoiding the direct use of the user-defined + types in ECPG and instead create a function or cast that converts + between the user-defined type and a primitive type that ECPG can + handle. Note, however, that type casts, especially implicit + ones, should be introduced into the type system very carefully. + + + + For example, + +CREATE FUNCTION create_complex(r double, i double) RETURNS complex +LANGUAGE SQL +IMMUTABLE +AS $$ SELECT $1 * complex '(1,0')' + $2 * complex '(0,1)' $$; + + After this definition, the following + +EXEC SQL BEGIN DECLARE SECTION; +double a, b, c, d; +EXEC SQL END DECLARE SECTION; + +a = 1; +b = 2; +c = 3; +d = 4; + +EXEC SQL INSERT INTO test_complex VALUES (create_complex(:a, :b), create_complex(:c, :d)); + + has the same effect as + +EXEC SQL INSERT INTO test_complex VALUES ('(1,2)', '(3,4)'); + + + + + + Indicators @@ -668,6 +1745,16 @@ EXEC SQL SELECT b INTO :val :val_ind FROM test1; positive, it means that the value is not null, but it was truncated when it was stored in the host variable. + + + If the argument -r no_indicator is passed to + the preprocessor ecpg, it works in + no-indicator mode. In no-indicator mode, if no + indicator variable is specified, null values are signaled (on + input and output) for character string types as empty string and + for integer types as the lowest possible value for type (for + example, INT_MIN for int). +
@@ -684,9 +1771,12 @@ EXEC SQL SELECT b INTO :val :val_ind FROM test1; provide in a string variable. - - The simplest way to execute an arbitrary SQL statement is to use - the command EXECUTE IMMEDIATE. For example: + + Executing statements without a result set + + + The simplest way to execute an arbitrary SQL statement is to use + the command EXECUTE IMMEDIATE. For example: EXEC SQL BEGIN DECLARE SECTION; const char *stmt = "CREATE TABLE test1 (...);"; @@ -694,18 +1784,26 @@ EXEC SQL END DECLARE SECTION; EXEC SQL EXECUTE IMMEDIATE :stmt; - You cannot execute statements that retrieve data (e.g., - SELECT) this way. - + EXECUTE IMMEDIATE can be used for SQL + statements that do not return a result set (e.g., + DDL, INSERT, UPDATE, + DELETE). You cannot execute statements that + retrieve data (e.g., SELECT) this way. The + next section describes how to do that. + + - - A more powerful way to execute arbitrary SQL statements is to - prepare them once and execute the prepared statement as often as - you like. It is also possible to prepare a generalized version of - a statement and then execute specific versions of it by - substituting parameters. When preparing the statement, write - question marks where you want to substitute parameters later. For - example: + + Executing a statement with input parameters + + + A more powerful way to execute arbitrary SQL statements is to + prepare them once and execute the prepared statement as often as + you like. It is also possible to prepare a generalized version of + a statement and then execute specific versions of it by + substituting parameters. When preparing the statement, write + question marks where you want to substitute parameters later. For + example: EXEC SQL BEGIN DECLARE SECTION; const char *stmt = "INSERT INTO test1 VALUES(?, ?);"; @@ -715,34 +1813,78 @@ EXEC SQL PREPARE mystmt FROM :stmt; ... EXEC SQL EXECUTE mystmt USING 42, 'foobar'; - If the statement you are executing returns values, then add an - INTO clause: + + + + When you don't need the prepared statement anymore, you should + deallocate it: + +EXEC SQL DEALLOCATE PREPARE name; + + + + + + Executing a statement with a result set + + + To execute an SQL statement with a single result row, + EXECUTE can be used. To save the result, add + an INTO clause. ?"; int v1, v2; -VARCHAR v3; +VARCHAR v3[50]; EXEC SQL END DECLARE SECTION; EXEC SQL PREPARE mystmt FROM :stmt; ... -EXEC SQL EXECUTE mystmt INTO v1, v2, v3 USING 37; +EXEC SQL EXECUTE mystmt INTO :v1, :v2, :v3 USING 37; ]]> - An EXECUTE command can have an - INTO clause, a USING clause, - both, or neither. - + An EXECUTE command can have an + INTO clause, a USING clause, + both, or neither. + - - When you don't need the prepared statement anymore, you should - deallocate it: + + If a query is expected to return more than one result row, a + cursor should be used, as in the following example. + (See for more details about the + cursor.) -EXEC SQL DEALLOCATE PREPARE name; - - - +EXEC SQL BEGIN DECLARE SECTION; +char dbaname[128]; +char datname[128]; +char *stmt = "SELECT u.usename as dbaname, d.datname " + " FROM pg_database d, pg_user u " + " WHERE d.datdba = u.usesysid"; +EXEC SQL END DECLARE SECTION; +EXEC SQL CONNECT TO testdb AS con1 USER testuser; + +EXEC SQL PREPARE stmt1 FROM :stmt; + +EXEC SQL DECLARE cursor1 CURSOR FOR stmt1; +EXEC SQL OPEN cursor1; + +EXEC SQL WHENEVER NOT FOUND DO BREAK; + +while (1) +{ + EXEC SQL FETCH cursor1 INTO :dbaname,:datname; + printf("dbaname=%s, datname=%s\n", dbaname, datname); +} + +EXEC SQL CLOSE cursor1; + +EXEC SQL COMMIT; +EXEC SQL DISCONNECT ALL; + + + + pgtypes library @@ -771,7 +1913,7 @@ free(out); - + The numeric type The numeric type offers to do calculations with arbitrary precision. See @@ -1094,7 +2236,7 @@ int PGTYPESnumeric_from_decimal(decimal *src, numeric *dst); - + The date type The date type in C enables your programs to deal with data of the SQL type @@ -1570,8 +2712,8 @@ int PGTYPESdate_defmt_asc(date *d, char *fmt, char *str); - - + + The timestamp type The timestamp type in C enables your programs to deal with data of the SQL @@ -2101,7 +3243,7 @@ int PGTYPEStimestamp_sub_interval(timestamp *tin, interval *span, timestamp *tou - + The interval type The interval type in C enables your programs to deal with data of the SQL @@ -2188,7 +3330,7 @@ int PGTYPESinterval_copy(interval *intvlsrc, interval *intvldest); - + The decimal type The decimal type is similar to the numeric type. However it is limited to @@ -2231,8 +3373,8 @@ void PGTYPESdecimal_free(decimal *var); - - + + errno values of pgtypeslib @@ -2281,7 +3423,8 @@ void PGTYPESdecimal_free(decimal *var); PGTYPES_DATE_BAD_DATE - + An invalid date string was passed to + the PGTYPESdate_from_asc function. @@ -2290,7 +3433,8 @@ void PGTYPESdecimal_free(decimal *var); PGTYPES_DATE_ERR_EARGS - + Invalid arguments were passed to the + PGTYPESdate_defmt_asc function. @@ -2299,7 +3443,8 @@ void PGTYPESdecimal_free(decimal *var); PGTYPES_DATE_ERR_ENOSHORTDATE - + An invalid token in the input string was found by the + PGTYPESdate_defmt_asc function. @@ -2308,7 +3453,10 @@ void PGTYPESdecimal_free(decimal *var); PGTYPES_INTVL_BAD_INTERVAL - + An invalid interval string was passed to the + PGTYPESinterval_from_asc function, or an + invalid interval value was passed to the + PGTYPESinterval_to_asc function. @@ -2317,7 +3465,8 @@ void PGTYPESdecimal_free(decimal *var); PGTYPES_DATE_ERR_ENOTDMY - + There was a mismatch in the day/month/year assignment in the + PGTYPESdate_defmt_asc function. @@ -2326,7 +3475,8 @@ void PGTYPESdecimal_free(decimal *var); PGTYPES_DATE_BAD_DAY - + An invalid day of the month value was found by + the PGTYPESdate_defmt_asc function. @@ -2335,7 +3485,8 @@ void PGTYPESdecimal_free(decimal *var); PGTYPES_DATE_BAD_MONTH - + An invalid month value was found by + the PGTYPESdate_defmt_asc function. @@ -2344,7 +3495,20 @@ void PGTYPESdecimal_free(decimal *var); PGTYPES_TS_BAD_TIMESTAMP - + An invalid timestamp string pass passed to + the PGTYPEStimestamp_from_asc function, + or an invalid timestamp value was passed to + the PGTYPEStimestamp_to_asc function. + + + + + + PGTYPES_TS_ERR_EINFTIME + + + An infinite timestamp value was encountered in a context that + cannot handle it. @@ -2352,7 +3516,7 @@ void PGTYPESdecimal_free(decimal *var); - + Special constants of pgtypeslib @@ -2394,7 +3558,7 @@ void PGTYPESdecimal_free(decimal *var); - Named SQL Descriptor Areas + Named SQL descriptor areas A named SQL descriptor area consists of a header, which contains @@ -2430,7 +3594,7 @@ EXEC SQL FETCH NEXT FROM mycursor INTO SQL DESCRIPTOR mydesc; 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; char *sql_stmt = "SELECT * FROM table1"; EXEC SQL END DECLARE SECTION; @@ -2445,7 +3609,7 @@ EXEC SQL DESCRIBE stmt1 INTO SQL DESCRIPTOR mydesc; so using DESCRIPTOR and SQL DESCRIPTOR produced named SQL Descriptor Areas. Now it is mandatory, omitting the SQL keyword produces SQLDA Descriptor Areas, - see . + see . @@ -2499,7 +3663,13 @@ EXEC SQL GET DESCRIPTOR name VALUE numDATETIME_INTERVAL_CODE (integer) - ? + 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. @@ -2646,7 +3816,7 @@ EXEC SQL GET DESCRIPTOR mydesc VALUE 1 :id = DATA; - SQLDA Descriptor Areas + SQLDA descriptor areas An SQLDA Descriptor Area is a C language structure which can be also used @@ -2668,56 +3838,80 @@ EXEC SQL DESCRIBE prepared_statement INTO mysqlda; - - The structure of SQLDA is: + + + The general flow of a program that uses SQLDA is: + + Prepare a query, and declare a cursor for it. + Declare an SQLDA for the result rows. + Declare an SQLDA for the input parameters, and initialize them (memory allocation, parameter settings). + Open a cursor with the input SQLDA. + Fetch rows from the cursor, and store them into an output SQLDA. + Read values from the output SQLDA into the host variables (with conversion if necessary). + Close the cursor. + Free the memory area allocated for the input SQLDA. + + + + SQLDA data structure + + + SQLDA uses three data structure + types: sqlda_t, sqlvar_t, + and struct sqlname. + + + + + PostgreSQL's SQLDA has a similar data structure to the one in + IBM DB2 Universal Database, so some technical information on + DB2's SQLDA could help understanding PostgreSQL's one better. + + + + + sqlda_t structure + + + The structure type sqlda_t is the type of the + actual SQLDA. It holds one record. And two or + more sqlda_t structures can be connected in a + linked list with the pointer in + the desc_next field, thus + representing an ordered collection of rows. So, when two or + more rows are fetched, the application can read them by + following the desc_next pointer in + each sqlda_t node. + + + + The definition of sqlda_t is: -#define NAMEDATALEN 64 - -struct sqlname -{ - short length; - char data[NAMEDATALEN]; -}; - -struct sqlvar_struct -{ - short sqltype; - short sqllen; - char *sqldata; - short *sqlind; - struct sqlname sqlname; -}; - struct sqlda_struct { - char sqldaid[8]; - long sqldabc; - short sqln; - short sqld; - struct sqlda_struct *desc_next; - struct sqlvar_struct sqlvar[1]; + char sqldaid[8]; + long sqldabc; + short sqln; + short sqld; + struct sqlda_struct *desc_next; + struct sqlvar_struct sqlvar[1]; }; -typedef struct sqlvar_struct sqlvar_t; -typedef struct sqlda_struct sqlda_t; +typedef struct sqlda_struct sqlda_t; - - - The allocated data for an SQLDA structure is variable as it depends on the - number of fields in a result set and also depends on the length of the string - data values in a record. The individual fields of the SQLDA - structure are: + The meaning of the fields is: sqldaid - It contains the "SQLDA " literal string. + It contains the literal string "SQLDA ". + sqldabc @@ -2726,6 +3920,7 @@ typedef struct sqlda_struct sqlda_t; + sqln @@ -2740,6 +3935,7 @@ typedef struct sqlda_struct sqlda_t; + sqld @@ -2748,6 +3944,7 @@ typedef struct sqlda_struct sqlda_t; + desc_next @@ -2761,15 +3958,43 @@ typedef struct sqlda_struct sqlda_t; sqlvar - This is the array of the fields in the result set. The fields are: + This is the array of the columns in the result set. + + + + + + + + + sqlvar_t structure + + + The structure type sqlvar_t holds a column value + and metadata such as type and length. The definition of the type + is: + + +struct sqlvar_struct +{ + short sqltype; + short sqllen; + char *sqldata; + short *sqlind; + struct sqlname sqlname; +}; + +typedef struct sqlvar_struct sqlvar_t; + + + The meaning of the fields is: - sqltype - It contains the type identifier of the field. For values, + Contains the type identifier of the field. For values, see enum ECPGttype in ecpgtype.h. @@ -2779,7 +4004,7 @@ typedef struct sqlda_struct sqlda_t; sqllen - It contains the binary length of the field. E.g. 4 bytes for ECPGt_int. + Contains the binary length of the field. e.g. 4 bytes for ECPGt_int. @@ -2788,7 +4013,8 @@ typedef struct sqlda_struct sqlda_t; sqldata - (char *)sqldata points to the data. + Points to the data. The format of the data is described + in . @@ -2797,8 +4023,8 @@ typedef struct sqlda_struct sqlda_t; sqlind - (char *)sqlind points to the NULL indicator for data. - 0 means NOT NULL, -1 means NULL. + Points to the null indicator. 0 means not null, -1 means + null. @@ -2807,22 +4033,37 @@ typedef struct sqlda_struct sqlda_t; sqlname - struct sqlname sqlname contains the name of the field - in a structure: + The the name of the field. + + + + + + + + + struct sqlname structure + + + A struct sqlname structure holds a column name. It + is used as a member of the sqlvar_t structure. The + definition of the structure is: +#define NAMEDATALEN 64 + struct sqlname { short length; char data[NAMEDATALEN]; }; - + The meaning of the fields is: length - sqlname.length contains the length of the field name. + Contains the length of the field name. @@ -2830,28 +4071,3756 @@ struct sqlname data - sqlname.data contains the actual field name. + Contains the actual field name. - - - + + + - + + Retreiving a result set using an SQLDA + + + + The general steps to retrieve a query result set through an + SQLDA are: + + Declare an sqlda_t structure to receive the result set. + Execute FETCH/EXECUTE/DESCRIBE commands to process a query specifying the declared SQLDA. + Check the number of records in the result set by looking at sqln, a member of the sqlda_t structure. + Get the values of each column from sqlvar[0], sqlvar[1], etc., members of the sqlda_t structure. + Go to next row (sqlda_t structure) by following the desc_next pointer, a member of the sqlda_t structure. + Repeat above as you need. + + + + Here is an example retrieving a result set through an SQLDA. + + + + First, declare a sqlda_t structure to receive the result set. + +sqlda_t *sqlda1; + + + + + Next, specify the SQLDA in a command. This is + a FETCH command example. + +EXEC SQL FETCH NEXT FROM cur1 INTO DESCRIPTOR sqlda1; + + + + + Run a loop following the linked list to retrieve the rows. + +sqlda_t *cur_sqlda; + +for (cur_sqlda = sqlda1; + cur_sqlda != NULL; + cur_sqlda = cur_sqlda->desc_next) +{ + ... +} + + + + + Inside the loop, run another loop to retrieve each column data + (sqlvar_t structure) of the row. + +for (i = 0; i < cur_sqlda->sqld; i++) +{ + sqlvar_t v = cur_sqlda->sqlvar[i]; + char *sqldata = v.sqldata; + short sqllen = v.sqllen; + ... +} + + + + + To get a column value, check the sqltype value, + a member of the sqlvar_t structure. Then, switch + to an appropriate way, depending on the column type, to copy + data from the sqlvar field to a host variable. + +char var_buf[1024]; + +switch (v.sqltype) +{ + case ECPGt_char: + memset(&var_buf, 0, sizeof(var_buf)); + memcpy(&var_buf, sqldata, (sizeof(var_buf) <= sqllen ? sizeof(var_buf) - 1 : sqllen)); + break; + + case ECPGt_int: /* integer */ + memcpy(&intval, sqldata, sqllen); + snprintf(var_buf, sizeof(var_buf), "%d", intval); + break; + + ... +} + + + + + + Passing query parameters using an SQLDA + + + + The general steps to use an SQLDA to pass input + parameters to a prepared query are: + + Create a prepared query (prepared statement) + Declare a sqlda_t structure as an input SQLDA. + Allocate memory area (as sqlda_t structure) for the input SQLDA. + Set (copy) input values in the allocated memory. + Open a cursor with specifying the input SQLDA. + + + + Here is an example. + + + + First, create a prepared statement. + +EXEC SQL BEGIN DECLARE SECTION; +char query[1024] = "SELECT d.oid, * FROM pg_database d, pg_stat_database s WHERE d.oid = s.datid AND (d.datname = ? OR d.oid = ?)"; +EXEC SQL END DECLARE SECTION; + +EXEC SQL PREPARE stmt1 FROM :query; + + + + + Next, allocate memory for an SQLDA, and set the number of input + parameters in sqln, a member variable of + the sqlda_t structure. When two or more input + parameters are required for the prepared query, the application + has to allocate additional memory space which is calculated by + (nr. of params - 1) * sizeof(sqlvar_t). The example shown here + allocates memory space for two input parameters. + +sqlda_t *sqlda2; + +sqlda2 = (sqlda_t *) malloc(sizeof(sqlda_t) + sizeof(sqlvar_t)); +memset(sqlda2, 0, sizeof(sqlda_t) + sizeof(sqlvar_t)); + +sqlda2->sqln = 2; /* number of input variables */ + + + + + After memory allocation, store the parameter values into the + sqlvar[] array. (This is same array used for + retrieving column values when the SQLDA is receiving a result + set.) In this example, the input parameters + are "postgres", having a string type, + and 1, having an integer type. + +sqlda2->sqlvar[0].sqltype = ECPGt_char; +sqlda2->sqlvar[0].sqldata = "postgres"; +sqlda2->sqlvar[0].sqllen = 8; + +int intval = 1; +sqlda2->sqlvar[1].sqltype = ECPGt_int; +sqlda2->sqlvar[1].sqldata = (char *) &intval; +sqlda2->sqlvar[1].sqllen = sizeof(intval); + + + + + By opening a cursor and specifying the SQLDA that was set up + beforehand, the input parameters are passed to the prepared + statement. + +EXEC SQL OPEN cur1 USING DESCRIPTOR sqlda2; + + + + + Finally, after using input SQLDAs, the allocated memory space + must be freed explicitly, unlike SQLDAs used for receiving query + results. + +free(sqlda2); + + + + + + A sample application using SQLDA + + + Here is an example program, which describes how to fetch access + statistics of the databases, specified by the input parameters, + from the system catalogs. + + + + This application joins two system tables, pg_database and + pg_stat_database on the database oid, and also fetches and shows + the database statistics which are retreived by two input + parameters (a database "postgres", and oid "1"). + + + + First, declare an SQLDA for input and an SQLDA for output. + +EXEC SQL include sqlda.h; + +sqlda_t *sqlda1; /* an output descriptor */ +sqlda_t *sqlda2; /* an input descriptor */ + + + + + Next, connect to the database, prepare a statement, and declare a + cursor for the prepared statement. + +int +main(void) +{ + EXEC SQL BEGIN DECLARE SECTION; + char query[1024] = "SELECT d.oid,* FROM pg_database d, pg_stat_database s WHERE d.oid=s.datid AND ( d.datname=? OR d.oid=? )"; + EXEC SQL END DECLARE SECTION; + + EXEC SQL CONNECT TO testdb AS con1 USER testuser; + + EXEC SQL PREPARE stmt1 FROM :query; + EXEC SQL DECLARE cur1 CURSOR FOR stmt1; + + + + + Next, put some values in the input SQLDA for the input + parameters. Allocate memory for the input SQLDA, and set the + number of input parameters to sqln. Store + type, value, and value length into sqltype, + sqldata, and sqllen in the + sqlvar structure. + + + /* Create SQLDA structure for input parameters. */ + sqlda2 = (sqlda_t *) malloc(sizeof(sqlda_t) + sizeof(sqlvar_t)); + memset(sqlda2, 0, sizeof(sqlda_t) + sizeof(sqlvar_t)); + sqlda2->sqln = 2; /* number of input variables */ + + sqlda2->sqlvar[0].sqltype = ECPGt_char; + sqlda2->sqlvar[0].sqldata = "postgres"; + sqlda2->sqlvar[0].sqllen = 8; + + intval = 1; + sqlda2->sqlvar[1].sqltype = ECPGt_int; + sqlda2->sqlvar[1].sqldata = (char *)&intval; + sqlda2->sqlvar[1].sqllen = sizeof(intval); + + + + + After setting up the input SQLDA, open a cursor with the input + SQLDA. + + + /* Open a cursor with input parameters. */ + EXEC SQL OPEN cur1 USING DESCRIPTOR sqlda2; + + + + + Fetch rows into the output SQLDA from the opened cursor. + (Generally, you have to call FETCH repeatedly + in the loop, to fetch all rows in the result set.) + + while (1) + { + sqlda_t *cur_sqlda; + + /* Assign descriptor to the cursor */ + EXEC SQL FETCH NEXT FROM cur1 INTO DESCRIPTOR sqlda1; + + + + + Next, retrieve the fetched records from the SQLDA, by following + the linked list of the sqlda_t structure. + + for (cur_sqlda = sqlda1 ; + cur_sqlda != NULL ; + cur_sqlda = cur_sqlda->desc_next) + { + ... + + + + + Read each columns in the first record. The number of columns is + stored in sqld, the actual data of the first + column is stored in sqlvar[0], both members of + the sqlda_t structure. + + + /* Print every column in a row. */ + for (i = 0; i < sqlda1->sqld; i++) + { + sqlvar_t v = sqlda1->sqlvar[i]; + char *sqldata = v.sqldata; + short sqllen = v.sqllen; + + strncpy(name_buf, v.sqlname.data, v.sqlname.length); + name_buf[v.sqlname.length] = '\0'; + + + + + Now, the column data is stored in the variable v. + Copy every datum into host variables, looking + at v.sqltype for the type of the column. + + switch (v.sqltype) { + int intval; + double doubleval; + unsigned long long int longlongval; + + case ECPGt_char: + memset(&var_buf, 0, sizeof(var_buf)); + memcpy(&var_buf, sqldata, (sizeof(var_buf) <= sqllen ? sizeof(var_buf)-1 : sqllen)); + break; + + case ECPGt_int: /* integer */ + memcpy(&intval, sqldata, sqllen); + snprintf(var_buf, sizeof(var_buf), "%d", intval); + break; + + ... + + default: + ... + } + + printf("%s = %s (type: %d)\n", name_buf, var_buf, v.sqltype); + } + + + + + Close the cursor after processing all of records, and disconnect + from the database. + + EXEC SQL CLOSE cur1; + EXEC SQL COMMIT; + + EXEC SQL DISCONNECT ALL; + + + + + The whole program is shown + in . + + + + Example SQLDA program + +#include <stdlib.h> +#include <string.h> +#include <stdlib.h> +#include <stdio.h> +#include <unistd.h> + +EXEC SQL include sqlda.h; + +sqlda_t *sqlda1; /* descriptor for output */ +sqlda_t *sqlda2; /* descriptor for input */ + +EXEC SQL WHENEVER NOT FOUND DO BREAK; +EXEC SQL WHENEVER SQLERROR STOP; + +int +main(void) +{ + EXEC SQL BEGIN DECLARE SECTION; + char query[1024] = "SELECT d.oid,* FROM pg_database d, pg_stat_database s WHERE d.oid=s.datid AND ( d.datname=? OR d.oid=? )"; + + int intval; + unsigned long long int longlongval; + EXEC SQL END DECLARE SECTION; + + EXEC SQL CONNECT TO uptimedb AS con1 USER uptime; + + EXEC SQL PREPARE stmt1 FROM :query; + EXEC SQL DECLARE cur1 CURSOR FOR stmt1; + + /* Create a SQLDA structure for an input parameter */ + sqlda2 = (sqlda_t *)malloc(sizeof(sqlda_t) + sizeof(sqlvar_t)); + memset(sqlda2, 0, sizeof(sqlda_t) + sizeof(sqlvar_t)); + sqlda2->sqln = 2; /* a number of input variables */ + + sqlda2->sqlvar[0].sqltype = ECPGt_char; + sqlda2->sqlvar[0].sqldata = "postgres"; + sqlda2->sqlvar[0].sqllen = 8; + + intval = 1; + sqlda2->sqlvar[1].sqltype = ECPGt_int; + sqlda2->sqlvar[1].sqldata = (char *) &intval; + sqlda2->sqlvar[1].sqllen = sizeof(intval); + + /* Open a cursor with input parameters. */ + EXEC SQL OPEN cur1 USING DESCRIPTOR sqlda2; + + while (1) + { + sqlda_t *cur_sqlda; + + /* Assign descriptor to the cursor */ + EXEC SQL FETCH NEXT FROM cur1 INTO DESCRIPTOR sqlda1; + + for (cur_sqlda = sqlda1 ; + cur_sqlda != NULL ; + cur_sqlda = cur_sqlda->desc_next) + { + int i; + char name_buf[1024]; + char var_buf[1024]; + + /* Print every column in a row. */ + for (i=0 ; i<cur_sqlda->sqld ; i++) + { + sqlvar_t v = cur_sqlda->sqlvar[i]; + char *sqldata = v.sqldata; + short sqllen = v.sqllen; + + strncpy(name_buf, v.sqlname.data, v.sqlname.length); + name_buf[v.sqlname.length] = '\0'; + + switch (v.sqltype) + { + case ECPGt_char: + memset(&var_buf, 0, sizeof(var_buf)); + memcpy(&var_buf, sqldata, (sizeof(var_buf)<=sqllen ? sizeof(var_buf)-1 : sqllen) ); + break; + + case ECPGt_int: /* integer */ + memcpy(&intval, sqldata, sqllen); + snprintf(var_buf, sizeof(var_buf), "%d", intval); + break; + + case ECPGt_long_long: /* bigint */ + memcpy(&longlongval, sqldata, sqllen); + snprintf(var_buf, sizeof(var_buf), "%lld", longlongval); + break; + + default: + { + int i; + memset(var_buf, 0, sizeof(var_buf)); + for (i = 0; i < sqllen; i++) + { + char tmpbuf[16]; + snprintf(tmpbuf, sizeof(tmpbuf), "%02x ", (unsigned char) sqldata[i]); + strncat(var_buf, tmpbuf, sizeof(var_buf)); + } + } + break; + } + + printf("%s = %s (type: %d)\n", name_buf, var_buf, v.sqltype); + } + + printf("\n"); + } + } + + EXEC SQL CLOSE cur1; + EXEC SQL COMMIT; + + EXEC SQL DISCONNECT ALL; + + return 0; +} + + + + The output of this example should look something like the + following (some numbers will vary). + + + +oid = 1 (type: 1) +datname = template1 (type: 1) +datdba = 10 (type: 1) +encoding = 0 (type: 5) +datistemplate = t (type: 1) +datallowconn = t (type: 1) +datconnlimit = -1 (type: 5) +datlastsysoid = 11510 (type: 1) +datfrozenxid = 379 (type: 1) +dattablespace = 1663 (type: 1) +datconfig = (type: 1) +datacl = {=c/uptime,uptime=CTc/uptime} (type: 1) +datid = 1 (type: 1) +datname = template1 (type: 1) +numbackends = 0 (type: 5) +xact_commit = 113606 (type: 9) +xact_rollback = 0 (type: 9) +blks_read = 130 (type: 9) +blks_hit = 7341714 (type: 9) +tup_returned = 38262679 (type: 9) +tup_fetched = 1836281 (type: 9) +tup_inserted = 0 (type: 9) +tup_updated = 0 (type: 9) +tup_deleted = 0 (type: 9) + +oid = 11511 (type: 1) +datname = postgres (type: 1) +datdba = 10 (type: 1) +encoding = 0 (type: 5) +datistemplate = f (type: 1) +datallowconn = t (type: 1) +datconnlimit = -1 (type: 5) +datlastsysoid = 11510 (type: 1) +datfrozenxid = 379 (type: 1) +dattablespace = 1663 (type: 1) +datconfig = (type: 1) +datacl = (type: 1) +datid = 11511 (type: 1) +datname = postgres (type: 1) +numbackends = 0 (type: 5) +xact_commit = 221069 (type: 9) +xact_rollback = 18 (type: 9) +blks_read = 1176 (type: 9) +blks_hit = 13943750 (type: 9) +tup_returned = 77410091 (type: 9) +tup_fetched = 3253694 (type: 9) +tup_inserted = 0 (type: 9) +tup_updated = 0 (type: 9) +tup_deleted = 0 (type: 9) + + + + + + + + Error Handling + + + This section describes how you can handle exceptional conditions + and warnings in an embedded SQL program. There are two + nonexclusive facilities for this. + + + + + Callbacks can be configured to handle warning and error + conditions using the WHENEVER command. + + + + + + Detailed information about the error or warning can be obtained + from the sqlca variable. + + + + + + + Setting callbacks + + + One simple method to catch errors and warnings is to set a + specific action to be executed whenever a particular condition + occurs. In general: + +EXEC SQL WHENEVER condition action; + + + + + condition can be one of the following: + + + + SQLERROR + + + The specified action is called whenever an error occurs during + the execution of an SQL statement. + + + + + + SQLWARNING + + + The specified action is called whenever a warning occurs + during the execution of an SQL statement. + + + + + + NOT FOUND + + + The specified action is called whenever an SQL statement + retrieves or affects zero rows. (This condition is not an + error, but you might be interested in handling it specially.) + + action can be one of the following: + + + + CONTINUE + + + This effectively means that the condition is ignored. This is + the default. + + + + + + GOTO label + GO TO label + + + Jump to the specified label (using a C goto + statement). + + + + + + SQLPRINT + + + Print a message to standard error. This is useful for simple + programs or during prototyping. The details of the message + cannot be configured. + + + + + + STOP + + + Call exit(1), which will terminate the + program. + + + + + + DO BREAK + + + Execute the C statement break. This should + only be used in loops or switch statements. + + + + + + CALL name (args) + DO name (args) + + + Call the specified C functions with the specified arguments. + + + + + + The SQL standard only provides for the actions + CONTINUE and GOTO (and + GO TO). + + + + Here is an example that you might want to use in a simple program. + It prints a simple message when a warning occurs and aborts the + program when an error happens: + +EXEC SQL WHENEVER SQLWARNING SQLPRINT; +EXEC SQL WHENEVER SQLERROR STOP; + + + + + The statement EXEC SQL WHENEVER is a directive + of the SQL preprocessor, not a C statement. The error or warning + actions that it sets apply to all embedded SQL statements that + appear below the point where the handler is set, unless a + different action was set for the same condition between the first + EXEC SQL WHENEVER and the SQL statement causing + the condition, regardless of the flow of control in the C program. + So neither of the two following C program excerpts will have the + desired effect: + +/* + * WRONG + */ +int main(int argc, char *argv[]) +{ + ... + if (verbose) { + EXEC SQL WHENEVER SQLWARNING SQLPRINT; + } + ... + EXEC SQL SELECT ...; + ... +} + + + +/* + * WRONG + */ +int main(int argc, char *argv[]) +{ + ... + set_error_handler(); + ... + EXEC SQL SELECT ...; + ... +} + +static void set_error_handler(void) +{ + EXEC SQL WHENEVER SQLERROR STOP; +} + + + + sqlca + + + For more powerful error handling, the embedded SQL interface + provides a global variable with the name sqlca + (SQL communication area) + that has the following structure: + +struct +{ + char sqlcaid[8]; + long sqlabc; + long sqlcode; + struct + { + int sqlerrml; + char sqlerrmc[SQLERRMC_LEN]; + } sqlerrm; + char sqlerrp[8]; + long sqlerrd[6]; + char sqlwarn[8]; + char sqlstate[5]; +} sqlca; + + (In a multithreaded program, every thread automatically gets its + own copy of sqlca. This works similarly to the + handling of the standard C global variable + errno.) + + + + sqlca covers both warnings and errors. If + multiple warnings or errors occur during the execution of a + statement, then sqlca will only contain + information about the last one. + + + + If no error occurred in the last SQL statement, + sqlca.sqlcode will be 0 and + sqlca.sqlstate will be + "00000". If a warning or error occurred, then + sqlca.sqlcode will be negative and + sqlca.sqlstate will be different from + "00000". A positive + sqlca.sqlcode indicates a harmless condition, + such as that the last query returned zero rows. + sqlcode and sqlstate are two + different error code schemes; details appear below. + + + + If the last SQL statement was successful, then + sqlca.sqlerrd[1] contains the OID of the + processed row, if applicable, and + sqlca.sqlerrd[2] contains the number of + processed or returned rows, if applicable to the command. + + + + In case of an error or warning, + sqlca.sqlerrm.sqlerrmc will contain a string + that describes the error. The field + sqlca.sqlerrm.sqlerrml contains the length of + the error message that is stored in + sqlca.sqlerrm.sqlerrmc (the result of + strlen(), not really interesting for a C + programmer). Note that some messages are too long to fit in the + fixed-size sqlerrmc array; they will be truncated. + + + + In case of a warning, sqlca.sqlwarn[2] is set + to W. (In all other cases, it is set to + something different from W.) If + sqlca.sqlwarn[1] is set to + W, then a value was truncated when it was + stored in a host variable. sqlca.sqlwarn[0] is + set to W if any of the other elements are set + to indicate a warning. + + + + The fields sqlcaid, + sqlcabc, + sqlerrp, and the remaining elements of + sqlerrd and + sqlwarn currently contain no useful + information. + + + + The structure sqlca is not defined in the SQL + standard, but is implemented in several other SQL database + systems. The definitions are similar at the core, but if you want + to write portable applications, then you should investigate the + different implementations carefully. + + + + Here is one example that combines the use of WHENEVER + and sqlca, printing out the contents + of sqlca when an error occurs. This is perhaps + useful for debugging or prototyping applications, before + installing a more user-friendly error handler. + + +EXEC SQL WHENEVER SQLERROR CALL print_sqlca(); + +void +print_sqlca() +{ + fprintf(stderr, "==== sqlca ====\n"); + fprintf(stderr, "sqlcode: %ld\n", sqlca.sqlcode); + fprintf(stderr, "sqlerrm.sqlerrml: %d\n", sqlca.sqlerrm.sqlerrml); + fprintf(stderr, "sqlerrm.sqlerrmc: %s\n", sqlca.sqlerrm.sqlerrmc); + fprintf(stderr, "sqlerrd: %ld %ld %ld %ld %ld %ld\n", sqlca.sqlerrd[0],sqlca.sqlerrd[1],sqlca.sqlerrd[2], + sqlca.sqlerrd[3],sqlca.sqlerrd[4],sqlca.sqlerrd[5]); + fprintf(stderr, "sqlwarn: %d %d %d %d %d %d %d %d\n", sqlca.sqlwarn[0], sqlca.sqlwarn[1], sqlca.sqlwarn[2], + sqlca.sqlwarn[3], sqlca.sqlwarn[4], sqlca.sqlwarn[5], + sqlca.sqlwarn[6], sqlca.sqlwarn[7]); + fprintf(stderr, "sqlstate: %5s\n", sqlca.sqlstate); + fprintf(stderr, "===============\n"); +} + + + The result could look as follows (here an error due to a + misspelled table name): + + +==== sqlca ==== +sqlcode: -400 +sqlerrm.sqlerrml: 49 +sqlerrm.sqlerrmc: relation "pg_databasep" does not exist on line 38 +sqlerrd: 0 0 0 0 0 0 +sqlwarn: 0 0 0 0 0 0 0 0 +sqlstate: 42P01 +=============== + + + + + + <literal>SQLSTATE</literal> vs <literal>SQLCODE</literal> + + + The fields sqlca.sqlstate and + sqlca.sqlcode are two different schemes that + provide error codes. Both are derived from the SQL standard, but + SQLCODE has been marked deprecated in the SQL-92 + edition of the standard and has been dropped in later editions. + Therefore, new applications are strongly encouraged to use + SQLSTATE. + + + + SQLSTATE is a five-character array. The five + characters contain digits or upper-case letters that represent + codes of various error and warning conditions. + SQLSTATE has a hierarchical scheme: the first + two characters indicate the general class of the condition, the + last three characters indicate a subclass of the general + condition. A successful state is indicated by the code + 00000. The SQLSTATE codes are for + the most part defined in the SQL standard. The + PostgreSQL server natively supports + SQLSTATE error codes; therefore a high degree + of consistency can be achieved by using this error code scheme + throughout all applications. For further information see + . + + + + SQLCODE, the deprecated error code scheme, is a + simple integer. A value of 0 indicates success, a positive value + indicates success with additional information, a negative value + indicates an error. The SQL standard only defines the positive + value +100, which indicates that the last command returned or + affected zero rows, and no specific negative values. Therefore, + this scheme can only achieve poor portability and does not have a + hierarchical code assignment. Historically, the embedded SQL + processor for PostgreSQL has assigned + some specific SQLCODE values for its use, which + are listed below with their numeric value and their symbolic name. + Remember that these are not portable to other SQL implementations. + To simplify the porting of applications to the + SQLSTATE scheme, the corresponding + SQLSTATE is also listed. There is, however, no + one-to-one or one-to-many mapping between the two schemes (indeed + it is many-to-many), so you should consult the global + SQLSTATE listing in + in each case. + + + + These are the assigned SQLCODE values: + + + + 0 (ECPG_NO_ERROR) + + + Indicates no error. (SQLSTATE 00000) + + + + + + 100 (ECPG_NOT_FOUND) + + + This is a harmless condition indicating that the last command + retrieved or processed zero rows, or that you are at the end of + the cursor. (SQLSTATE 02000) + + + + When processing a cursor in a loop, you could use this code as + a way to detect when to abort the loop, like this: + +while (1) +{ + EXEC SQL FETCH ... ; + if (sqlca.sqlcode == ECPG_NOT_FOUND) + break; +} + + But WHENEVER NOT FOUND DO BREAK effectively + does this internally, so there is usually no advantage in + writing this out explicitly. + + + + + + -12 (ECPG_OUT_OF_MEMORY) + + + Indicates that your virtual memory is exhausted. The numeric + value is defined as -ENOMEM. (SQLSTATE + YE001) + + + + + + -200 (ECPG_UNSUPPORTED) + + + Indicates the preprocessor has generated something that the + library does not know about. Perhaps you are running + incompatible versions of the preprocessor and the + library. (SQLSTATE YE002) + + + + + + -201 (ECPG_TOO_MANY_ARGUMENTS) + + + This means that the command specified more host variables than + the command expected. (SQLSTATE 07001 or 07002) + + + + + + -202 (ECPG_TOO_FEW_ARGUMENTS) + + + This means that the command specified fewer host variables than + the command expected. (SQLSTATE 07001 or 07002) + + + + + + -203 (ECPG_TOO_MANY_MATCHES) + + + This means a query has returned multiple rows but the statement + was only prepared to store one result row (for example, because + the specified variables are not arrays). (SQLSTATE 21000) + + + + + + -204 (ECPG_INT_FORMAT) + + + The host variable is of type int and the datum in + the database is of a different type and contains a value that + cannot be interpreted as an int. The library uses + strtol() for this conversion. (SQLSTATE + 42804) + + + + + + -205 (ECPG_UINT_FORMAT) + + + The host variable is of type unsigned int and the + datum in the database is of a different type and contains a + value that cannot be interpreted as an unsigned + int. The library uses strtoul() + for this conversion. (SQLSTATE 42804) + + + + + + -206 (ECPG_FLOAT_FORMAT) + + + The host variable is of type float and the datum + in the database is of another type and contains a value that + cannot be interpreted as a float. The library + uses strtod() for this conversion. + (SQLSTATE 42804) + + + + + + -207 (ECPG_NUMERIC_FORMAT) + + + The host variable is of type numeric and the datum + in the database is of another type and contains a value that + cannot be interpreted as a numeric value. + (SQLSTATE 42804) + + + + + + -208 (ECPG_INTERVAL_FORMAT) + + + The host variable is of type interval and the datum + in the database is of another type and contains a value that + cannot be interpreted as an interval value. + (SQLSTATE 42804) + + + + + + -209 (ECPG_DATE_FORMAT) + + + The host variable is of type date and the datum in + the database is of another type and contains a value that + cannot be interpreted as a date value. + (SQLSTATE 42804) + + + + + + -210 (ECPG_TIMESTAMP_FORMAT) + + + The host variable is of type timestamp and the + datum in the database is of another type and contains a value + that cannot be interpreted as a timestamp value. + (SQLSTATE 42804) + + + + + + -211 (ECPG_CONVERT_BOOL) + + + This means the host variable is of type bool and + the datum in the database is neither 't' nor + 'f'. (SQLSTATE 42804) + + + + + + -212 (ECPG_EMPTY) + + + The statement sent to the PostgreSQL + server was empty. (This cannot normally happen in an embedded + SQL program, so it might point to an internal error.) (SQLSTATE + YE002) + + + + + + -213 (ECPG_MISSING_INDICATOR) + + + A null value was returned and no null indicator variable was + supplied. (SQLSTATE 22002) + + + + + + -214 (ECPG_NO_ARRAY) + + + An ordinary variable was used in a place that requires an + array. (SQLSTATE 42804) + + + + + + -215 (ECPG_DATA_NOT_ARRAY) + + + The database returned an ordinary variable in a place that + requires array value. (SQLSTATE 42804) + + + + + + + -216 (ECPG_ARRAY_INSERT) + + + The value could not be inserted into the array. (SQLSTATE + 42804) + + + +]]> + + + -220 (ECPG_NO_CONN) + + + The program tried to access a connection that does not exist. + (SQLSTATE 08003) + + + + + + -221 (ECPG_NOT_CONN) + + + The program tried to access a connection that does exist but is + not open. (This is an internal error.) (SQLSTATE YE002) + + + + + + -230 (ECPG_INVALID_STMT) + + + The statement you are trying to use has not been prepared. + (SQLSTATE 26000) + + + + + + -239 (ECPG_INFORMIX_DUPLICATE_KEY) + + + Duplicate key error, violation of unique constraint (Informix + compatibility mode). (SQLSTATE 23505) + + + + + + -240 (ECPG_UNKNOWN_DESCRIPTOR) + + + The descriptor specified was not found. The statement you are + trying to use has not been prepared. (SQLSTATE 33000) + + + + + + -241 (ECPG_INVALID_DESCRIPTOR_INDEX) + + + The descriptor index specified was out of range. (SQLSTATE + 07009) + + + + + + -242 (ECPG_UNKNOWN_DESCRIPTOR_ITEM) + + + An invalid descriptor item was requested. (This is an internal + error.) (SQLSTATE YE002) + + + + + + -243 (ECPG_VAR_NOT_NUMERIC) + + + During the execution of a dynamic statement, the database + returned a numeric value and the host variable was not numeric. + (SQLSTATE 07006) + + + + + + -244 (ECPG_VAR_NOT_CHAR) + + + During the execution of a dynamic statement, the database + returned a non-numeric value and the host variable was numeric. + (SQLSTATE 07006) + + + + + + -284 (ECPG_INFORMIX_SUBSELECT_NOT_ONE) + + + A result of the subquery is not single row (Informix + compatibility mode). (SQLSTATE 21000) + + + + + + -400 (ECPG_PGSQL) + + + Some error caused by the PostgreSQL + server. The message contains the error message from the + PostgreSQL server. + + + + + + -401 (ECPG_TRANS) + + + The PostgreSQL server signaled that + we cannot start, commit, or rollback the transaction. + (SQLSTATE 08007) + + + + + + -402 (ECPG_CONNECT) + + + The connection attempt to the database did not succeed. + (SQLSTATE 08001) + + + + + + -403 (ECPG_DUPLICATE_KEY) + + + Duplicate key error, violation of unique constraint. (SQLSTATE + 23505) + + + + + + -404 (ECPG_SUBSELECT_NOT_ONE) + + + A result for the subquery is not single row. (SQLSTATE 21000) + + + + + + + -600 (ECPG_WARNING_UNRECOGNIZED) + + + An unrecognized warning was received from the server. + + + + + + -601 (ECPG_WARNING_QUERY_IGNORED) + + + Current transaction is aborted. Queries are ignored until the + end of the transaction block. + + + +]]> + + + -602 (ECPG_WARNING_UNKNOWN_PORTAL) + + + An invalid cursor name was specified. (SQLSTATE 34000) + + + + + + -603 (ECPG_WARNING_IN_TRANSACTION) + + + Transaction is in progress. (SQLSTATE 25001) + + + + + + -604 (ECPG_WARNING_NO_TRANSACTION) + + + There is no active (in-progress) transaction. (SQLSTATE 25P01) + + + + + + -605 (ECPG_WARNING_PORTAL_EXISTS) + + + An existing cursor name was specified. (SQLSTATE 42P03) + + + + + + + + + + + Preprocessor directives + + + Several preprocessor directives are available that modify how + the ecpg preprocessor parses and processes a + file. + + + + Including files + + + To include an external file into your embedded SQL program, use: + +EXEC SQL INCLUDE filename; +EXEC SQL INCLUDE <filename>; +EXEC SQL INCLUDE "filename"; + + The embedded SQL preprocessor will look for a file named + filename.h, + preprocess it, and include it in the resulting C output. Thus, + embedded SQL statements in the included file are handled correctly. + + + + The ecpg preprocessor will search a file at + several directories in following order: + + + current directory + /usr/local/include + PostgreSQL include directory, defined at build time (e.g., /usr/local/pgsql/include) + /usr/include + + + But when EXEC SQL INCLUDE + "filename" is used, only the + current directory is searched. + + + + In each directory, the preprocessor will first look for the file + name as given, and if not found will append .h + to the file name and try again (unless the specified file name + already has that suffix). + + + + Note that EXEC SQL INCLUDE is not the same as: + +#include <filename.h> + + because this file would not be subject to SQL command preprocessing. + Naturally, you can continue to use the C + #include directive to include other header + files. + + + + + The include file name is case-sensitive, even though the rest of + the EXEC SQL INCLUDE command follows the normal + SQL case-sensitivity rules. + + + + + + The define and undef directives + + Similar to the directive #define that is known from C, + embedded SQL has a similar concept: + +EXEC SQL DEFINE name; +EXEC SQL DEFINE name value; + + So you can define a name: + +EXEC SQL DEFINE HAVE_FEATURE; + + And you can also define constants: + +EXEC SQL DEFINE MYNUMBER 12; +EXEC SQL DEFINE MYSTRING 'abc'; + + Use undef to remove a previous definition: + +EXEC SQL UNDEF MYNUMBER; + + + + + Of course you can continue to use the C versions #define + and #undef in your embedded SQL program. The difference + is where your defined values get evaluated. If you use EXEC SQL + DEFINE then the ecpg preprocessor evaluates the defines and substitutes + the values. For example if you write: + +EXEC SQL DEFINE MYNUMBER 12; +... +EXEC SQL UPDATE Tbl SET col = MYNUMBER; + + then ecpg will already do the substitution and your C compiler will never + see any name or identifier MYNUMBER. Note that you cannot use + #define for a constant that you are going to use in an + embedded SQL query because in this case the embedded SQL precompiler is not + able to see this declaration. + + + + + ifdef, ifndef, else, elif, and endif directives + + You can use the following directives to compile code sections conditionally: + + + + EXEC SQL ifdef name; + + + Checks a name and processes subsequent lines if + name has been created with EXEC SQL define + name. + + + + + + EXEC SQL ifndef name; + + + Checks a name and processes subsequent lines if + name has not been created with + EXEC SQL define name. + + + + + + EXEC SQL else; + + + Starts processing an alternative section to a section introduced by + either EXEC SQL ifdef name or + EXEC SQL ifndef name. + + + + + + EXEC SQL elif name; + + + Checks name and starts an alternative section if + name has been created with EXEC SQL define + name. + + + + + + EXEC SQL endif; + + + Ends an alternative section. + + + + + + + + Example: + +EXEC SQL ifndef TZVAR; +EXEC SQL SET TIMEZONE TO 'GMT'; +EXEC SQL elif TZNAME; +EXEC SQL SET TIMEZONE TO TZNAME; +EXEC SQL else; +EXEC SQL SET TIMEZONE TO TZVAR; +EXEC SQL endif; + + + + + + + + Processing Embedded SQL Programs + + + Now that you have an idea how to form embedded SQL C programs, you + probably want to know how to compile them. Before compiling you + run the file through the embedded SQL + C preprocessor, which converts the + SQL statements you used to special function + calls. After compiling, you must link with a special library that + contains the needed functions. These functions fetch information + from the arguments, perform the SQL command using + the libpq interface, and put the result + in the arguments specified for output. + + + + The preprocessor program is called ecpg and is + included in a normal PostgreSQL installation. + Embedded SQL programs are typically named with an extension + .pgc. If you have a program file called + prog1.pgc, you can preprocess it by simply + calling: + +ecpg prog1.pgc + + This will create a file called prog1.c. If + your input files do not follow the suggested naming pattern, you + can specify the output file explicitly using the + option. + + + + The preprocessed file can be compiled normally, for example: + +cc -c prog1.c + + The generated C source files include header files from the + PostgreSQL installation, so if you installed + PostgreSQL in a location that is not searched by + default, you have to add an option such as + -I/usr/local/pgsql/include to the compilation + command line. + + + + To link an embedded SQL program, you need to include the + libecpg library, like so: + +cc -o myprog prog1.o prog2.o ... -lecpg + + Again, you might have to add an option like + -L/usr/local/pgsql/lib to that command line. + + + + If you manage the build process of a larger project using + make, it might be convenient to include + the following implicit rule to your makefiles: + +ECPG = ecpg + +%.c: %.pgc + $(ECPG) $< + + + + + The complete syntax of the ecpg command is + detailed in . + + + + The ecpg library is thread-safe by + default. However, you might need to use some threading + command-line options to compile your client code. + + + + + Library Functions + + + The libecpg library primarily contains + hidden functions that are used to implement the + functionality expressed by the embedded SQL commands. But there + are some functions that can usefully be called directly. Note that + this makes your code unportable. + + + + + + ECPGdebug(int on, FILE + *stream) turns on debug + logging if called with the first argument non-zero. Debug logging + is done on stream. The log contains + all SQL statements with all the input + variables inserted, and the results from the + PostgreSQL server. This can be very + useful when searching for errors in your SQL + statements. + + + + On Windows, if the ecpg libraries and an application are + compiled with different flags, this function call will crash the + application because the internal representation of the + FILE pointers differ. Specifically, + multithreaded/single-threaded, release/debug, and static/dynamic + flags should be the same for the library and all applications using + that library. + + + + + + + ECPGget_PGconn(const char *connection_name) + returns the library database connection handle identified by the given name. + If connection_name is set to NULL, the current + connection handle is returned. If no connection handle can be identified, the function returns + NULL. The returned connection handle can be used to call any other functions + from libpq, if necessary. + + + + It is a bad idea to manipulate database connection handles made from ecpg directly + with libpq routines. + + + + + + + ECPGtransactionStatus(const char *connection_name) + returns the current transaction status of the given connection identified by connection_name. + See and libpq's PQtransactionStatus() for details about the returned status codes. + + + + + + ECPGstatus(int lineno, + const char* connection_name) + returns true if you are connected to a database and false if not. + connection_name can be NULL + if a single connection is being used. + + + + + + + Large Objects + + + Large objects are not directly supported by ECPG, but ECPG + application can manipulate large objects through the libpq large + object functions, obtaining the necessary PGconn + object by calling the ECPGget_PGconn() + function. (However, use of + the ECPGget_PGconn() function and touching + PGconn objects directly should be done very carefully + and ideally not mixed with other ECPG database access calls.) + + + + For more details about the ECPGget_PGconn(), see + . For information about the large + object function interface, see . + + + + Large object functions have to be called in a transaction block, so + when autocommit is off, BEGIN commands have to + be isssued explicitly. + + + + shows an example program that + illustrates how to create, write, and read a large object in an + ECPG application. + + + + ECPG program accessing large objects + +#include +#include +#include + +EXEC SQL WHENEVER SQLERROR STOP; + +int +main(void) +{ + PGconn *conn; + Oid loid; + int fd; + char buf[256]; + int buflen = 256; + char buf2[256]; + int rc; + + memset(buf, 1, buflen); + + EXEC SQL CONNECT TO testdb AS con1; + + conn = ECPGget_PGconn("con1"); + printf("conn = %p\n", conn); + + /* create */ + loid = lo_create(conn, 0); + if (loid < 0) + printf("lo_create() failed: %s", PQerrorMessage(conn)); + + printf("loid = %d\n", loid); + + /* write test */ + fd = lo_open(conn, loid, INV_READ|INV_WRITE); + if (fd < 0) + printf("lo_open() failed: %s", PQerrorMessage(conn)); + + printf("fd = %d\n", fd); + + rc = lo_write(conn, fd, buf, buflen); + if (rc < 0) + printf("lo_write() failed\n"); + + rc = lo_close(conn, fd); + if (rc < 0) + printf("lo_close() failed: %s", PQerrorMessage(conn)); + + /* read test */ + fd = lo_open(conn, loid, INV_READ); + if (fd < 0) + printf("lo_open() failed: %s", PQerrorMessage(conn)); + + printf("fd = %d\n", fd); + + rc = lo_read(conn, fd, buf2, buflen); + if (rc < 0) + printf("lo_read() failed\n"); + + rc = lo_close(conn, fd); + if (rc < 0) + printf("lo_close() failed: %s", PQerrorMessage(conn)); + + /* check */ + rc = memcmp(buf, buf2, buflen); + printf("memcmp() = %d\n", rc); + + /* cleanup */ + rc = lo_unlink(conn, loid); + if (rc < 0) + printf("lo_unlink() failed: %s", PQerrorMessage(conn)); + + EXEC SQL COMMIT; + EXEC SQL DISCONNECT ALL; + return 0; +} +]]> + + + + + <acronym>C++</acronym> Applications + + + ECPG has some limited support for C++ applications. This section + describes some caveats. + + + + The ecpg preprocessor takes an input file + written in C (or something like C) and embedded SQL commands, + converts the embedded SQL commands into C language chunks, and + finally generates a .c file. The header file + declarations of the library functions used by the C language chunks + that ecpg generates are wrapped + in extern "C" { ... } blocks when used under + C++, so they should work seamlessly in C++. + + + + In general, however, the ecpg preprocessor only + understands C; it does not handle the special syntax and reserved + words of the C++ language. So, some embedded SQL code written in + C++ application code that uses complicated features specific to C++ + might fail to be preprocessed correctly or might not work as + expected. + + + + A safe way to use the embedded SQL code in a C++ application is + hiding the ECPG calls in a C module, which the C++ application code + calls into to access the database, and linking that together with + the rest of the C++ code. See + about that. + + + + Scope for host variables + + + The ecpg preprocessor understands the scope of + variables in C. In the C language, this is rather simple because + the scopes of variables is based on their code blocks. In C++, + however, the class member variables are referenced in a different + code block from the declared position, so + the ecpg preprocessor will not understand the + scope of the class member variables. + + + + For example, in the following case, the ecpg + preprocessor cannot find any declaration for the + variable dbname in the test + method, so an error will occur. + + +class TestCpp +{ + EXEC SQL BEGIN DECLARE SECTION; + char dbname[1024]; + EXEC SQL END DECLARE SECTION; + + public: + TestCpp(); + void test(); + ~TestCpp(); +}; + +TestCpp::TestCpp() +{ + EXEC SQL CONNECT TO testdb1; +} + +void Test::test() +{ + EXEC SQL SELECT current_database() INTO :dbname; + printf("current_database = %s\n", dbname); +} + +TestCpp::~TestCpp() +{ + EXEC SQL DISCONNECT ALL; +} + + + This code will result in an error like this: + +ecpg test_cpp.pgc +test_cpp.pgc:28: ERROR: variable "dbname" is not declared + + + + + To avoid this scope issue, the test method + could be modified to use a local variable as intermediate storage. + But this approach is only a poor workaround, because it uglifies + the code and reduces performance. + + +void TestCpp::test() +{ + EXEC SQL BEGIN DECLARE SECTION; + char tmp[1024]; + EXEC SQL END DECLARE SECTION; + + EXEC SQL SELECT current_database() INTO :tmp; + strlcpy(dbname, tmp, sizeof(tmp)); + + printf("current_database = %s\n", dbname); +} + + + + + + C++ application development with external C module + + + If you understand these technical limitations of + the ecpg preprocessor in C++, you might come to + the conclusion that linking C objects and C++ objects at the link + stage to enable C++ applications to use ECPG features could be + better than writing some embedded SQL commands in C++ code + directly. This section describes a way to separate some embedded + SQL commands from C++ application code with a simple example. In + this example, the application is implemented in C++, while C and + ECPG is used to connect to the PostgreSQL server. + + + + Three kinds of files have to be created: a C file + (*.pgc), a header file, and a C++ file: + + + + test_mod.pgc + + + A sub-routine module to execute SQL commands embedded in C. + It is going to be converted + into test_mod.c by the preprocessor. + + +#include "test_mod.h" +#include <stdio.h> + +void +db_connect() +{ + EXEC SQL CONNECT TO testdb1; +} + +void +db_test() +{ + EXEC SQL BEGIN DECLARE SECTION; + char dbname[1024]; + EXEC SQL END DECLARE SECTION; + + EXEC SQL SELECT current_database() INTO :dbname; + printf("current_database = %s\n", dbname); +} + +void +db_disconnect() +{ + EXEC SQL DISCONNECT ALL; +} + + + + + + + test_mod.h + + + A header file with declarations of the functions in the C + module (test_mod.pgc). It is included by + test_cpp.cpp. This file has to have an + extern "C" block around the declarations, + because it will be linked from the C++ module. + + +#ifdef __cplusplus +extern "C" { +#endif + +void db_connect(); +void db_test(); +void db_disconnect(); + +#ifdef __cplusplus +} +#endif + + + + + + + test_cpp.cpp + + + The main code for the application, including + the main routine, and in this example a + C++ class. + + +#include "test_mod.h" + +class TestCpp +{ + public: + TestCpp(); + void test(); + ~TestCpp(); +}; + +TestCpp::TestCpp() +{ + db_connect(); +} + +void +TestCpp::test() +{ + db_test(); +} + +TestCpp::~TestCpp() +{ + db_disconnect(); +} + +int +main(void) +{ + TestCpp *t = new TestCpp(); + + t->test(); + return 0; +} + + + + + + + + + To build the application, proceed as follows. Convert + test_mod.pgc into test_mod.c by + running ecpg, and generate + test_mod.o by compiling + test_mod.c with the C compiler: + +ecpg -o test_mod.c test_mod.pgc +cc -c test_mod.c -o test_mod.o + + + + + Next, generate test_cpp.o by compiling + test_cpp.cpp with the C++ compiler:. + +c++ -c test_cpp.cpp -o test_cpp.o + + + + + Finally, link these object files, test_cpp.o + and test_mod.o, into one executable, using the C++ + compiler driver: + +c++ test_cpp.o test_mod.o -lecpg -o test_cpp + + + + + + + Embedded SQL Commands + + + This section describes all SQL commands that are specific to + embedded SQL. Also refer to the SQL commands listed + in , which can also be used in + embedded SQL, unless stated otherwise. + + + + + ALLOCATE DESCRIPTOR + allocate an SQL descriptor area + + + + +ALLOCATE DESCRIPTOR name + + + + + Description + + + ALLOCATE DESCRIPTOR allocates a new named SQL + descriptor area, which can be used to exchange data between the + PostgreSQL server and the host program. + + + + Descriptor areas should be freed after use using + the DEALLOCATE DESCRIPTOR command. + + + + + Parameters + + + + name + + + A name of SQL descriptor, case sensitive. This can be an SQL + identifier or a host variable. + + + + + + + + Examples + + +EXEC SQL ALLOCATE DESCRIPTOR mydesc; + + + + + Compatibility + + + ALLOCATE DESCRIPTOR is specified in the SQL + standard. + + + + + See Also + + + + + + + + + + + + CONNECT + establish a database connection + + + + +CONNECT TO connection_target [ AS connection_name ] [ USER connection_user_name ] +CONNECT TO DEFAULT +CONNECT connection_user_name +DATABASE connection_target + + + + + Description + + + The CONNECT command establishes a connection + between the client and the PostgreSQL server. + + + + + Parameters + + + + connection_target + + + connection_target + specifies the target server of the connection on one of + several forms. + + + + [ database_name ] [ @host ] [ :port ] + + + Connect over TCP/IP + + + + + + unix:postgresql://host [ :port ] / [ database_name ] [ ?connection_option ] + + + Connect over Unix-domain sockets + + + + + + tcp:postgresql://host [ :port ] / [ database_name ] [ ?connection_option ] + + + Connect over TCP/IP + + + + + + SQL string constant + + + containing a value in one of the above forms + + + + + + host variable + + + host variable of type char[] + or VARCHAR[] containing a value in one of the + above forms + + + + + + + + + + connection_object + + + An optional identifier for the connection, so that it can be + referred to in other commands. This can be an SQL identifier + or a host variable. + + + + + + connection_user + + + The user name for the database connection. + + + + This parameter can also specify user name and password, using one the forms + user_name/password, + user_name IDENTIFIED BY password, or + user_name USING password. + + + + User name and password can be SQL identifiers, string + constants, or host variables. + + + + + + DEFAULT + + + Use all default connection parameters, as defined by libpq. + + + + + + + + Examples + + + Here a several variants for specifying connection parameters: + +EXEC SQL CONNECT TO "connectdb" AS main; +EXEC SQL CONNECT TO "connectdb" AS second; +EXEC SQL CONNECT TO "unix:postgresql://200.46.204.71/connectdb" AS main USER connectuser; +EXEC SQL CONNECT TO "unix:postgresql://localhost/connectdb" AS main USER connectuser; +EXEC SQL CONNECT TO 'connectdb' AS main; +EXEC SQL CONNECT TO 'unix:postgresql://localhost/connectdb' AS main USER :user; +EXEC SQL CONNECT TO :db AS :id; +EXEC SQL CONNECT TO :db USER connectuser USING :pw; +EXEC SQL CONNECT TO @localhost AS main USER connectdb; +EXEC SQL CONNECT TO REGRESSDB1 as main; +EXEC SQL CONNECT TO AS main USER connectdb; +EXEC SQL CONNECT TO connectdb AS :id; +EXEC SQL CONNECT TO connectdb AS main USER connectuser/connectdb; +EXEC SQL CONNECT TO connectdb AS main; +EXEC SQL CONNECT TO connectdb@localhost AS main; +EXEC SQL CONNECT TO tcp:postgresql://localhost/ USER connectdb; +EXEC SQL CONNECT TO tcp:postgresql://localhost/connectdb USER connectuser IDENTIFIED BY connectpw; +EXEC SQL CONNECT TO tcp:postgresql://localhost:20/connectdb USER connectuser IDENTIFIED BY connectpw; +EXEC SQL CONNECT TO unix:postgresql://localhost/ AS main USER connectdb; +EXEC SQL CONNECT TO unix:postgresql://localhost/connectdb AS main USER connectuser; +EXEC SQL CONNECT TO unix:postgresql://localhost/connectdb USER connectuser IDENTIFIED BY "connectpw"; +EXEC SQL CONNECT TO unix:postgresql://localhost/connectdb USER connectuser USING "connectpw"; +EXEC SQL CONNECT TO unix:postgresql://localhost/connectdb?connect_timeout=14 USER connectuser; + + + + + Here is an example program that illustrates the use of host + variables to specify connection parameters: + +int +main(void) +{ +EXEC SQL BEGIN DECLARE SECTION; + char *dbname = "testdb"; /* database name */ + char *user = "testuser"; /* connection user name */ + char *connection = "tcp:postgresql://localhost:5432/testdb"; + /* connection string */ + char ver[256]; /* buffer to store the version string */ +EXEC SQL END DECLARE SECTION; + + ECPGdebug(1, stderr); + + EXEC SQL CONNECT TO :dbname USER :user; + EXEC SQL SELECT version() INTO :ver; + EXEC SQL DISCONNECT; + + printf("version: %s\n", ver); + + EXEC SQL CONNECT TO :connection USER :user; + EXEC SQL SELECT version() INTO :ver; + EXEC SQL DISCONNECT; + + printf("version: %s\n", ver); + + return 0; +} + + + + + + Compatibility + + + CONNECT is specified in the SQL standard, but + the format of the connection parameters is + implementation-specific. + + + + + See Also + + + + + + + + + + + DEALLOCATE DESCRIPTOR + deallocate an SQL descriptor area + + + + +DEALLOCATE DESCRIPTOR name + + + + + Description + + + DEALLOCATE DESCRIPTOR deallocates a named SQL + descriptor area. + + + + + Parameters + + + + name + + + The name of the descriptor which is going to be deallocated. + It is case sensitive. This can be an SQL identifier or a host + variable. + + + + + + + + Examples + + +EXEC SQL DEALLOCATE DESCRIPTOR mydesc; + + + + + Compatibility + + + DEALLOCATE DESCRIPTOR is specified in the SQL + standard. + + + + + See Also + + + + + + + + + + + + DECLARE + define a cursor + + + + +DECLARE cursor_name [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ] CURSOR [ { WITH | WITHOUT } HOLD ] FOR prepared_name +DECLARE cursor_name [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ] CURSOR [ { WITH | WITHOUT } HOLD ] FOR query + + + + + Description + + + DECLARE declares a cursor for iterating over + the result set of a prepared statement. This command has + slightly different semantics from the direct SQL + command DECLARE: Whereas the latter executes a + query and prepares the result set for retrieval, this embedded + SQL command merely declares a name as a loop + variable for iterating over the result set of a query; + the actual execution happens when the cursor is opened with + the OPEN command. + + + + + Parameters + + + + cursor_name + + + A cursor name, case sensitive. This can be an SQL identifier + or a host variable. + + + + + + prepared_name + + + The name of a prepared query, either as an SQL identfier or a + host variable. + + + + + + query + + + A or + command which will provide the + rows to be returned by the cursor. + + + + + + + For the meaning of the cursor options, + see . + + + + + Examples + + + Examples declaring a cursor for a query: + +EXEC SQL DECLARE C CURSOR FOR SELECT * FROM My_Table; +EXEC SQL DECLARE C CURSOR FOR SELECT Item1 FROM T; +EXEC SQL DECLARE cur1 CURSOR FOR SELECT version(); + + + + + An example declaring a cursor for a prepared statement: + +EXEC SQL PREPARE stmt1 AS SELECT version(); +EXEC SQL DECLARE cur1 CURSOR FOR stmt1; + + + + + + Compatibility + + + DECLARE is specified in the SQL standard. + + + + + See Also + + + + + + + + + + + + DESCRIBE + obtain information about a prepared statement or result set + + + + +DESCRIBE [ OUTPUT ] prepared_name USING [ SQL ] DESCRIPTOR descriptor_name +DESCRIBE [ OUTPUT ] prepared_name INTO [ SQL ] DESCRIPTOR descriptor_name +DESCRIBE [ OUTPUT ] prepared_name INTO sqlda_name + + + + + Description + + + DECLARE retrieves metadata information about + the result columns contained in a prepared statement, without + actually fetching a row. + + + + + Parameters + + + + prepared_name + + + The name of a prepared statement. This can be an SQL + identifier or a host variable. + + + + + + descriptor_name + + + A descriptor name. It is case sensitive. It can be an SQL + identifier or a host variable. + + + + + + sqlda_name + + + The name of an SQLDA variable. + + + + + + + + Examples + + +EXEC SQL ALLOCATE DESCRIPTOR mydesc; +EXEC SQL PREPARE stmt1 FROM :sql_stmt; +EXEC SQL DESCRIBE stmt1 INTO SQL DESCRIPTOR mydesc; +EXEC SQL GET DESCRIPTOR mydesc VALUE 1 :charvar = NAME; +EXEC SQL DEALLOCATE DESCRIPTOR mydesc; + + + + + Compatibility + + + DESCRIBE is specified in the SQL standard. + + + + + See Also + + + + + + + + + + + DISCONNECT + terminate a database connection + + + + +DISCONNECT connection_name +DISCONNECT [ CURRENT ] +DISCONNECT DEFAULT +DISCONNECT ALL + + + + + Description + + + DISCONNECT closes a connection (or all + connections) to the database. + + + + + Parameters + + + + connection_name + + + A database connection name established by + the CONNECT command. + + + + + + CURRENT + + + Close the current connection, which is either + the most recently opened connection, or the connection set by + the SET CONNECTION command. This is also + the default if no argument is given to + the DISCONNECT command. + + + + + + DEFAULT + + + Close the default connection. + + + + + + ALL + + + Close all open connections. + + + + + + + + Examples + + +int +main(void) +{ + EXEC SQL CONNECT TO testdb AS DEFAULT USER testuser; + EXEC SQL CONNECT TO testdb AS con1 USER testuser; + EXEC SQL CONNECT TO testdb AS con2 USER testuser; + EXEC SQL CONNECT TO testdb AS con3 USER testuser; + + EXEC SQL DISCONNECT CURRENT; /* close con3 */ + EXEC SQL DISCONNECT DEFAULT; /* close DEFAULT */ + EXEC SQL DISCONNECT ALL; /* close con2 and con1 */ + + return 0; +} + + + + + Compatibility + + + DISCONNECT is specified in the SQL standard. + + + + + See Also + + + + + + + + + + + EXECUTE IMMEDIATE + dynamically prepare and execute a statement + + + + +EXECUTE IMMEDIATE string + + + + + Description + + + EXECUTE IMMEDIATE immediately prepares and + executes a dynamically specified SQL statement, without + retrieving result rows. + + + + + Parameters + + + + string + + + A literal C string or a host variable containing the SQL + statement to be executed. + + + + + + + + Examples + + + Here is an example that executes an INSERT + statement using EXECUTE IMMEDIATE and a host + variable named command: + +sprintf(command, "INSERT INTO test (name, amount, letter) VALUES ('db: ''r1''', 1, 'f')"); +EXEC SQL EXECUTE IMMEDIATE :command; + + + + + + Compatibility + + + EXECUTE IMMEDIATE is specified in the SQL standard. + + + + + + + GET DESCRIPTOR + get information from an SQL descriptor area + + + + +GET DESCRIPTOR descriptor_name :cvariable = descriptor_header_item [, ... ] +GET DESCRIPTOR descriptor_name VALUE column_number :cvariable = descriptor_item [, ... ] + + + + + Description + + + GET DESCRIPTOR retrieves information about a + query result set from an SQL descriptor area and stores it into + host variables. A descriptor area is typically populated + using FETCH or SELECT + before using this command to transfer the information into host + language variables. + + + + This command has two forms: The first form retrieves + descriptor header items, which apply to the result + set in its entirety. One example is the row count. The second + form, which requires the column number as additional parameter, + retrieves information about a particular column. Examples are + the column name and the actual column value. + + + + + Parameters + + + + descriptor_name + + + A descriptor name. + + + + + + descriptor_header_item + + + A token identifying which header information item to retrieve. + Only COUNT, to get the number of columns in the + result set, is currently supported. + + + + + + column_number + + + The number of the column about which information is to be + retrieved. The count starts at 1. + + + + + + descriptor_item + + + A token identifying which item of information about a column + to retrieve. See for + a list of supported items. + + + + + + cvariable + + + A host variable that will receive the data retrieved from the + descriptor area. + + + + + + + + Examples + + + An example to retrieve the number of columns in a result set: + +EXEC SQL GET DESCRIPTOR d :d_count = COUNT; + + + + + An example to retrieve a data length in the first column: + +EXEC SQL GET DESCRIPTOR d VALUE 1 :d_returned_octet_length = RETURNED_OCTET_LENGTH; + + + + + An example to retrieve the data body of the second column as a + string: + +EXEC SQL GET DESCRIPTOR d VALUE 2 :d_data = DATA; + + + + + Here is an example for a whole procedure of + executing SELECT current_database(); and showing the number of + columns, the column data length, and the column data: + +int +main(void) +{ +EXEC SQL BEGIN DECLARE SECTION; + int d_count; + char d_data[1024]; + int d_returned_octet_length; +EXEC SQL END DECLARE SECTION; + + EXEC SQL CONNECT TO testdb AS con1 USER testuser; + EXEC SQL ALLOCATE DESCRIPTOR d; + + /* Declare, open a cursor, and assign a descriptor to the cursor */ + EXEC SQL DECLARE cur CURSOR FOR SELECT current_database(); + EXEC SQL OPEN cur; + EXEC SQL FETCH NEXT FROM cur INTO SQL DESCRIPTOR d; + + /* Get a number of total columns */ + EXEC SQL GET DESCRIPTOR d :d_count = COUNT; + printf("d_count = %d\n", d_count); + + /* Get length of a returned column */ + EXEC SQL GET DESCRIPTOR d VALUE 1 :d_returned_octet_length = RETURNED_OCTET_LENGTH; + printf("d_returned_octet_length = %d\n", d_returned_octet_length); + + /* Fetch the returned column as a string */ + EXEC SQL GET DESCRIPTOR d VALUE 1 :d_data = DATA; + printf("d_data = %s\n", d_data); + + /* Closing */ + EXEC SQL CLOSE cur; + EXEC SQL COMMIT; + + EXEC SQL DEALLOCATE DESCRIPTOR d; + EXEC SQL DISCONNECT ALL; + + return 0; +} + + When the example is executed, the result will look like this: + +d_count = 1 +d_returned_octet_length = 6 +d_data = testdb + + + + + + Compatibility + + + GET DESCRIPTOR is specified in the SQL standard. + + + + + See Also + + + + + + + + + + + OPEN + open a dynamic cursor + + + + +OPEN cursor_name +OPEN cursor_name USING value [, ... ] +OPEN cursor_name USING SQL DESCRIPTOR descriptor_name + + + + + Description + + + OPEN opens a cursor and optionally binds + actual values to the placeholders in the cursor's declaration. + The cursor must previously have been declared with + the DECLARE command. The execution + of OPEN causes the query to start executing on + the server. + + + + + Parameters + + + + cursor_name + + + The name of the cursor to be opened. This can be an SQL + identifier or a host variable. + + + + + + value + + + A value to be bound to a placeholder in the cursor. This can + be an SQL constant, a host variable, or a host variable with + indicator. + + + + + + descriptor_name + + + The name of a descriptor containing values to be bound to the + placeholders in the cursor. This can be an SQL identifier or + a host variable. + + + + + + + + Examples + + +EXEC SQL OPEN a; +EXEC SQL OPEN d USING 1, 'test'; +EXEC SQL OPEN c1 USING SQL DESCRIPTOR mydesc; +EXEC SQL OPEN :curname1; + + + + + Compatibility + + + OPEN is specified in the SQL standard. + + + + + See Also + + + + + + + + + + + PREPARE + prepare a statement for execution + + + + +PREPARE name FROM string + + + + + Description + + + PREPARE prepares a statement dynamically + specified as a string for execution. This is different from the + direct SQL statement , which can also + be used in embedded programs. The + command is used to execute either kind of prepared statement. + + + + + Parameters + + + + prepared_name + + + An identifier for the prepared query. + + + + + + string + + + A literal C string or a host variable containing a preparable + statement, one of the SELECT, INSERT, UPDATE, or + DELETE. + + + + + + + + Examples + +char *stmt = "SELECT * FROM test1 WHERE a = ? AND b = ?"; + +EXEC SQL ALLOCATE DESCRIPTOR outdesc; +EXEC SQL PREPARE foo FROM :stmt; + +EXEC SQL EXECUTE foo USING SQL DESCRIPTOR indesc INTO SQL DESCRIPTOR outdesc; + + + + + Compatibility + + + PREPARE is specified in the SQL standard. + + + + + See Also + + + + + + + + + + SET AUTOCOMMIT + set the autocommit behavior of the current session + + + + +SET AUTOCOMMIT { = | TO } { ON | OFF } + + + + + Description + + + SET AUTOCOMMIT sets the autocommit behavior of + the current database session. By default, embedded SQL programs + are not in autocommit mode, + so COMMIT needs to be issued explicitly when + desired. This command can change the session to autocommit mode, + where each individual statement is committed implicitly. + + + + + Compatibility + + + SET AUTOCOMMIT is an extension of PostgreSQL ECPG. + + + + + + + SET CONNECTION + select a database connection + + + + +SET CONNECTION [ TO | = ] connection_name + + + + + Description + + + SET CONNECTION sets the current + database connection, which is the one that all commands use + unless overridden. + + + + + Parameters + + + + connection_name + + + A database connection name established by + the CONNECT command. + + + + + + DEFAULT + + + Set the connection to the default connection. + + + + + + + + Examples + + +EXEC SQL SET CONNECTION TO con2; +EXEC SQL SET CONNECTION = con1; + + + + + Compatibility + + + SET CONNECTION is specified in the SQL standard. + + + + + See Also + + + + + + + + + + + SET DESCRIPTOR + set information in an SQL descriptor area + + + + +SET DESCRIPTOR descriptor_name descriptor_header_item = value [, ... ] +SET DESCRIPTOR descriptor_name VALUE number descriptor_item = value [, ...] + + + + + Description + + + SET DESCRIPTOR populates an SQL descriptor + area with values. The descriptor area is then typically used to + bind parameters in a prepared query execution. + + + + This command has two forms: The first form applies to the + descriptor header, which is independent of a + particular datum. The second form assigns values to particular + datums, identified by number. + + + + + Parameters + + + + descriptor_name + + + A descriptor name. + + + + + + descriptor_header_item + + + A token identifying which header information item to set. + Only COUNT, to set the number of descriptor + items, is currently supported. + + + + + + number + + + The number of the descriptor item to set. The count starts at + 1. + + + + + + descriptor_item + + + A token identifiying which item of information to set in the + descriptor. See for a + list of supported items. + + + + + + value + + + A value to store into the descriptor item. This can be an SQL + constant or a host variable. + + + + + + + + Examples + +EXEC SQL SET DESCRIPTOR indesc COUNT = 1; +EXEC SQL SET DESCRIPTOR indesc VALUE 1 DATA = 2; +EXEC SQL SET DESCRIPTOR indesc VALUE 1 DATA = :val1; +EXEC SQL SET DESCRIPTOR indesc VALUE 2 INDICATOR = :val1, DATA = 'some string'; +EXEC SQL SET DESCRIPTOR indesc VALUE 2 INDICATOR = :val2null, DATA = :val2; + + + + + Compatibility + + + SET DESCRIPTOR is specified in the SQL standard. + + + + + See Also + + + + + + + + + + + TYPE + define a new data type + + + + +TYPE type_name IS ctype + + + + + Description + + + The TYPE command defines a new C type. It is + equivalent to putting a typedef into a declare + section. + + + + This command is only recognized when ecpg is + run with the option. + + + + + Parameters + + + + type_name + + + The name for the new type. It must be a valid C type name. + + + + + + ctype + + + A C type specification. + + + + + + + + Examples + + +EXEC SQL TYPE customer IS + struct + { + varchar name[50]; + int phone; + }; + +EXEC SQL TYPE cust_ind IS + struct ind + { + short name_ind; + short phone_ind; + }; + +EXEC SQL TYPE c IS char reference; +EXEC SQL TYPE ind IS union { int integer; short smallint; }; +EXEC SQL TYPE intarray IS int[AMOUNT]; +EXEC SQL TYPE str IS varchar[BUFFERSIZ]; +EXEC SQL TYPE string IS char[11]; + + + + Here is an example program that uses EXEC SQL + TYPE: + +EXEC SQL WHENEVER SQLERROR SQLPRINT; + +EXEC SQL TYPE tt IS + struct + { + varchar v[256]; + int i; + }; + +EXEC SQL TYPE tt_ind IS + struct ind { + short v_ind; + short i_ind; + }; + +int +main(void) +{ +EXEC SQL BEGIN DECLARE SECTION; + tt t; + tt_ind t_ind; +EXEC SQL END DECLARE SECTION; + + EXEC SQL CONNECT TO testdb AS con1; + + EXEC SQL SELECT current_database(), 256 INTO :t:t_ind LIMIT 1; + + printf("t.v = %s\n", t.v.arr); + printf("t.i = %d\n", t.i); + + printf("t_ind.v_ind = %d\n", t_ind.v_ind); + printf("t_ind.i_ind = %d\n", t_ind.i_ind); + + EXEC SQL DISCONNECT con1; + + return 0; +} + + + The output from this program looks like this: + +t.v = testdb +t.i = 256 +t_ind.v_ind = 0 +t_ind.i_ind = 0 + + + + + + Compatibility + + + The TYPE command is a PostgreSQL extension. + + + + + + + VAR + define a variable + + + + +VAR varname IS ctype + + + + + Description + + + The VAR command defines a host variable. It + is equivalent to an ordinary C variable definition inside a + declare section. + + + + + Parameters + + + + varname + + + A C variable name. + + + + + + ctype + + + A C type specification. + + + + + + + + Examples + + +EXEC SQL VAR vc IS VARCHAR[10]; +EXEC SQL VAR boolvar IS bool; + + + + + Compatibility + + + The VAR command is a PostgreSQL extension. + + + + + + + WHENEVER + specify the action to be taken when an SQL statement causes a specific class condition to be raised + + + + +WHENEVER { NOT FOUND | SQLERROR | SQLWARNING } action + + + + + Description + + + Define a behavior which is called on the special cases (Rows not + found, SQL warnings or errors) in the result of SQL execution. + + + + + Parameters + + + See for a description of the + parameters. + + + + + Examples + + +EXEC SQL WHENEVER NOT FOUND CONTINUE; +EXEC SQL WHENEVER NOT FOUND DO BREAK; +EXEC SQL WHENEVER SQLWARNING SQLPRINT; +EXEC SQL WHENEVER SQLWARNING DO warn(); +EXEC SQL WHENEVER SQLERROR sqlprint; +EXEC SQL WHENEVER SQLERROR CALL print2(); +EXEC SQL WHENEVER SQLERROR DO handle_error("select"); +EXEC SQL WHENEVER SQLERROR DO sqlnotice(NULL, NONO); +EXEC SQL WHENEVER SQLERROR DO sqlprint(); +EXEC SQL WHENEVER SQLERROR GOTO error_label; +EXEC SQL WHENEVER SQLERROR STOP; + + + + A typical application is the use of WHENEVER NOT FOUND + BREAK to handle looping through result sets: + +int +main(void) +{ + EXEC SQL CONNECT TO testdb AS con1; + EXEC SQL ALLOCATE DESCRIPTOR d; + EXEC SQL DECLARE cur CURSOR FOR SELECT current_database(), 'hoge', 256; + EXEC SQL OPEN cur; + + /* when end of result set reached, break out of while loop */ + EXEC SQL WHENEVER NOT FOUND DO BREAK; + + while (1) + { + EXEC SQL FETCH NEXT FROM cur INTO SQL DESCRIPTOR d; + ... + } + + EXEC SQL CLOSE cur; + EXEC SQL COMMIT; + + EXEC SQL DEALLOCATE DESCRIPTOR d; + EXEC SQL DISCONNECT ALL; + + return 0; +} + + + + + + Compatibility + + + WHENEVER is specified in the SQL standard, but + most of the actions are PostgreSQL extensions. + + + - <productname>Informix</productname> compatibility mode + <productname>Informix</productname> Compatibility Mode ecpg can be run in a so-called Informix compatibility mode. If this mode is active, it tries to behave as if it were the Informix @@ -2866,6 +7835,17 @@ $INSERT INTO test(i, j) VALUES (7, :j); $COMMIT; + + + + There must not be any white space between the $ + and a following preprocessor directive, that is, + include, define, ifdef, + etc. Otherwise, the preprocessor will parse the token as a host + variable. + + + There are two compatibility modes: INFORMIX, INFORMIX_SE @@ -2893,7 +7873,7 @@ $COMMIT; find support in ECPG for that either. - + Additional types The Informix-special "string" pseudo-type for storing right-trimmed character string data is now @@ -2909,7 +7889,7 @@ EXEC SQL FETCH MYCUR INTO :userid; - + Additional/missing embedded SQL statements @@ -2944,51 +7924,50 @@ EXEC SQL CLOSE DATABASE; FREE statement_name is a synonym for DEALLOCATE PREPARE statement_name. - - + + - - Informix-compatible SQLDA Descriptor Areas + + Informix-compatible SQLDA descriptor areas Informix-compatible mode supports a different structure than the one described in . See below: struct sqlvar_compat { - short sqltype; - int sqllen; - char *sqldata; - short *sqlind; - char *sqlname; - char *sqlformat; - short sqlitype; - short sqlilen; - char *sqlidata; - int sqlxid; - char *sqltypename; - short sqltypelen; - short sqlownerlen; - short sqlsourcetype; - char *sqlownername; - int sqlsourceid; - - char *sqlilongdata; - int sqlflags; - void *sqlreserved; + short sqltype; + int sqllen; + char *sqldata; + short *sqlind; + char *sqlname; + char *sqlformat; + short sqlitype; + short sqlilen; + char *sqlidata; + int sqlxid; + char *sqltypename; + short sqltypelen; + short sqlownerlen; + short sqlsourcetype; + char *sqlownername; + int sqlsourceid; + char *sqlilongdata; + int sqlflags; + void *sqlreserved; }; struct sqlda_compat { - short sqld; - struct sqlvar_compat *sqlvar; - char desc_name[19]; - short desc_occ; - struct sqlda_compat *desc_next; - void *reserved; + short sqld; + struct sqlvar_compat *sqlvar; + char desc_name[19]; + short desc_occ; + struct sqlda_compat *desc_next; + void *reserved; }; typedef struct sqlvar_compat sqlvar_t; @@ -2998,7 +7977,7 @@ typedef struct sqlda_compat sqlda_t; The global properties are: - + sqld @@ -3010,7 +7989,7 @@ typedef struct sqlda_compat sqlda_t; - sqlvar + sqlvar Pointer to the per-field properties. @@ -3229,7 +8208,7 @@ EXEC SQL INCLUDE sqlda.h; - + Additional functions @@ -3245,7 +8224,7 @@ int decadd(decimal *arg1, decimal *arg2, decimal *sum); (arg1), a pointer to the second operand of type decimal (arg2) and a pointer to a value of type decimal that will contain the sum (sum). On success, the function returns 0. - ECPG_INFORMIX_NUM_OVERFLOW is returned in case of overflow and + ECPG_INFORMIX_NUM_OVERFLOW is returned in case of overflow and ECPG_INFORMIX_NUM_UNDERFLOW in case of underflow. -1 is returned for other failures and errno is set to the respective errno number of the pgtypeslib. @@ -4287,7 +9266,7 @@ risnull(CINTTYPE, (char *) &i); - + Additional constants Note that all constants here describe errors and all of them are defined @@ -4450,1102 +9429,6 @@ risnull(CINTTYPE, (char *) &i); - - Error Handling - - - This section describes how you can handle exceptional conditions - and warnings in an embedded SQL program. There are several - nonexclusive facilities for this. - - - - Setting Callbacks - - - One simple method to catch errors and warnings is to set a - specific action to be executed whenever a particular condition - occurs. In general: - -EXEC SQL WHENEVER condition action; - - - - - condition can be one of the following: - - - - SQLERROR - - - The specified action is called whenever an error occurs during - the execution of an SQL statement. - - - - - - SQLWARNING - - - The specified action is called whenever a warning occurs - during the execution of an SQL statement. - - - - - - NOT FOUND - - - The specified action is called whenever an SQL statement - retrieves or affects zero rows. (This condition is not an - error, but you might be interested in handling it specially.) - - - - - - - - action can be one of the following: - - - - CONTINUE - - - This effectively means that the condition is ignored. This is - the default. - - - - - - GOTO label - GO TO label - - - Jump to the specified label (using a C goto - statement). - - - - - - SQLPRINT - - - Print a message to standard error. This is useful for simple - programs or during prototyping. The details of the message - cannot be configured. - - - - - - STOP - - - Call exit(1), which will terminate the - program. - - - - - - DO BREAK - - - Execute the C statement break. This should - only be used in loops or switch statements. - - - - - - CALL name (args) - DO name (args) - - - Call the specified C functions with the specified arguments. - - - - - - The SQL standard only provides for the actions - CONTINUE and GOTO (and - GO TO). - - - - Here is an example that you might want to use in a simple program. - It prints a simple message when a warning occurs and aborts the - program when an error happens: - -EXEC SQL WHENEVER SQLWARNING SQLPRINT; -EXEC SQL WHENEVER SQLERROR STOP; - - - - - The statement EXEC SQL WHENEVER is a directive - of the SQL preprocessor, not a C statement. The error or warning - actions that it sets apply to all embedded SQL statements that - appear below the point where the handler is set, unless a - different action was set for the same condition between the first - EXEC SQL WHENEVER and the SQL statement causing - the condition, regardless of the flow of control in the C program. - So neither of the two following C program excerpts will have the - desired effect: - -/* - * WRONG - */ -int main(int argc, char *argv[]) -{ - ... - if (verbose) { - EXEC SQL WHENEVER SQLWARNING SQLPRINT; - } - ... - EXEC SQL SELECT ...; - ... -} - - - -/* - * WRONG - */ -int main(int argc, char *argv[]) -{ - ... - set_error_handler(); - ... - EXEC SQL SELECT ...; - ... -} - -static void set_error_handler(void) -{ - EXEC SQL WHENEVER SQLERROR STOP; -} - - - - - - sqlca - - - For more powerful error handling, the embedded SQL interface - provides a global variable with the name sqlca - that has the following structure: - -struct -{ - char sqlcaid[8]; - long sqlabc; - long sqlcode; - struct - { - int sqlerrml; - char sqlerrmc[SQLERRMC_LEN]; - } sqlerrm; - char sqlerrp[8]; - long sqlerrd[6]; - char sqlwarn[8]; - char sqlstate[5]; -} sqlca; - - (In a multithreaded program, every thread automatically gets its - own copy of sqlca. This works similarly to the - handling of the standard C global variable - errno.) - - - - sqlca covers both warnings and errors. If - multiple warnings or errors occur during the execution of a - statement, then sqlca will only contain - information about the last one. - - - - If no error occurred in the last SQL statement, - sqlca.sqlcode will be 0 and - sqlca.sqlstate will be - "00000". If a warning or error occurred, then - sqlca.sqlcode will be negative and - sqlca.sqlstate will be different from - "00000". A positive - sqlca.sqlcode indicates a harmless condition, - such as that the last query returned zero rows. - sqlcode and sqlstate are two - different error code schemes; details appear below. - - - - If the last SQL statement was successful, then - sqlca.sqlerrd[1] contains the OID of the - processed row, if applicable, and - sqlca.sqlerrd[2] contains the number of - processed or returned rows, if applicable to the command. - - - - In case of an error or warning, - sqlca.sqlerrm.sqlerrmc will contain a string - that describes the error. The field - sqlca.sqlerrm.sqlerrml contains the length of - the error message that is stored in - sqlca.sqlerrm.sqlerrmc (the result of - strlen(), not really interesting for a C - programmer). Note that some messages are too long to fit in the - fixed-size sqlerrmc array; they will be truncated. - - - - In case of a warning, sqlca.sqlwarn[2] is set - to W. (In all other cases, it is set to - something different from W.) If - sqlca.sqlwarn[1] is set to - W, then a value was truncated when it was - stored in a host variable. sqlca.sqlwarn[0] is - set to W if any of the other elements are set - to indicate a warning. - - - - The fields sqlcaid, - sqlcabc, - sqlerrp, and the remaining elements of - sqlerrd and - sqlwarn currently contain no useful - information. - - - - The structure sqlca is not defined in the SQL - standard, but is implemented in several other SQL database - systems. The definitions are similar at the core, but if you want - to write portable applications, then you should investigate the - different implementations carefully. - - - - - <literal>SQLSTATE</literal> vs <literal>SQLCODE</literal> - - - The fields sqlca.sqlstate and - sqlca.sqlcode are two different schemes that - provide error codes. Both are derived from the SQL standard, but - SQLCODE has been marked deprecated in the SQL-92 - edition of the standard and has been dropped in later editions. - Therefore, new applications are strongly encouraged to use - SQLSTATE. - - - - SQLSTATE is a five-character array. The five - characters contain digits or upper-case letters that represent - codes of various error and warning conditions. - SQLSTATE has a hierarchical scheme: the first - two characters indicate the general class of the condition, the - last three characters indicate a subclass of the general - condition. A successful state is indicated by the code - 00000. The SQLSTATE codes are for - the most part defined in the SQL standard. The - PostgreSQL server natively supports - SQLSTATE error codes; therefore a high degree - of consistency can be achieved by using this error code scheme - throughout all applications. For further information see - . - - - - SQLCODE, the deprecated error code scheme, is a - simple integer. A value of 0 indicates success, a positive value - indicates success with additional information, a negative value - indicates an error. The SQL standard only defines the positive - value +100, which indicates that the last command returned or - affected zero rows, and no specific negative values. Therefore, - this scheme can only achieve poor portability and does not have a - hierarchical code assignment. Historically, the embedded SQL - processor for PostgreSQL has assigned - some specific SQLCODE values for its use, which - are listed below with their numeric value and their symbolic name. - Remember that these are not portable to other SQL implementations. - To simplify the porting of applications to the - SQLSTATE scheme, the corresponding - SQLSTATE is also listed. There is, however, no - one-to-one or one-to-many mapping between the two schemes (indeed - it is many-to-many), so you should consult the global - SQLSTATE listing in - in each case. - - - - These are the assigned SQLCODE values: - - - - 0 (ECPG_NO_ERROR) - - - Indicates no error. (SQLSTATE 00000) - - - - - - 100 (ECPG_NOT_FOUND) - - - This is a harmless condition indicating that the last command - retrieved or processed zero rows, or that you are at the end of - the cursor. (SQLSTATE 02000) - - - - - - -12 (ECPG_OUT_OF_MEMORY) - - - Indicates that your virtual memory is exhausted. The numeric - value is defined as -ENOMEM. (SQLSTATE - YE001) - - - - - - -200 (ECPG_UNSUPPORTED) - - - Indicates the preprocessor has generated something that the - library does not know about. Perhaps you are running - incompatible versions of the preprocessor and the - library. (SQLSTATE YE002) - - - - - - -201 (ECPG_TOO_MANY_ARGUMENTS) - - - This means that the command specified more host variables than - the command expected. (SQLSTATE 07001 or 07002) - - - - - - -202 (ECPG_TOO_FEW_ARGUMENTS) - - - This means that the command specified fewer host variables than - the command expected. (SQLSTATE 07001 or 07002) - - - - - - -203 (ECPG_TOO_MANY_MATCHES) - - - This means a query has returned multiple rows but the statement - was only prepared to store one result row (for example, because - the specified variables are not arrays). (SQLSTATE 21000) - - - - - - -204 (ECPG_INT_FORMAT) - - - The host variable is of type int and the datum in - the database is of a different type and contains a value that - cannot be interpreted as an int. The library uses - strtol() for this conversion. (SQLSTATE - 42804) - - - - - - -205 (ECPG_UINT_FORMAT) - - - The host variable is of type unsigned int and the - datum in the database is of a different type and contains a - value that cannot be interpreted as an unsigned - int. The library uses strtoul() - for this conversion. (SQLSTATE 42804) - - - - - - -206 (ECPG_FLOAT_FORMAT) - - - The host variable is of type float and the datum - in the database is of another type and contains a value that - cannot be interpreted as a float. The library - uses strtod() for this conversion. - (SQLSTATE 42804) - - - - - - -207 (ECPG_NUMERIC_FORMAT) - - - The host variable is of type numeric and the datum - in the database is of another type and contains a value that - cannot be interpreted as a numeric value. - (SQLSTATE 42804) - - - - - - -208 (ECPG_INTERVAL_FORMAT) - - - The host variable is of type interval and the datum - in the database is of another type and contains a value that - cannot be interpreted as an interval value. - (SQLSTATE 42804) - - - - - - -209 (ECPG_DATE_FORMAT) - - - The host variable is of type date and the datum in - the database is of another type and contains a value that - cannot be interpreted as a date value. - (SQLSTATE 42804) - - - - - - -210 (ECPG_TIMESTAMP_FORMAT) - - - The host variable is of type timestamp and the - datum in the database is of another type and contains a value - that cannot be interpreted as a timestamp value. - (SQLSTATE 42804) - - - - - - -211 (ECPG_CONVERT_BOOL) - - - This means the host variable is of type bool and - the datum in the database is neither 't' nor - 'f'. (SQLSTATE 42804) - - - - - - -212 (ECPG_EMPTY) - - - The statement sent to the PostgreSQL - server was empty. (This cannot normally happen in an embedded - SQL program, so it might point to an internal error.) (SQLSTATE - YE002) - - - - - - -213 (ECPG_MISSING_INDICATOR) - - - A null value was returned and no null indicator variable was - supplied. (SQLSTATE 22002) - - - - - - -214 (ECPG_NO_ARRAY) - - - An ordinary variable was used in a place that requires an - array. (SQLSTATE 42804) - - - - - - -215 (ECPG_DATA_NOT_ARRAY) - - - The database returned an ordinary variable in a place that - requires array value. (SQLSTATE 42804) - - - - - - - -216 (ECPG_ARRAY_INSERT) - - - The value could not be inserted into the array. (SQLSTATE - 42804) - - - -]]> - - - -220 (ECPG_NO_CONN) - - - The program tried to access a connection that does not exist. - (SQLSTATE 08003) - - - - - - -221 (ECPG_NOT_CONN) - - - The program tried to access a connection that does exist but is - not open. (This is an internal error.) (SQLSTATE YE002) - - - - - - -230 (ECPG_INVALID_STMT) - - - The statement you are trying to use has not been prepared. - (SQLSTATE 26000) - - - - - - -239 (ECPG_INFORMIX_DUPLICATE_KEY) - - - Duplicate key error, violation of unique constraint (Informix - compatibility mode). (SQLSTATE 23505) - - - - - - -240 (ECPG_UNKNOWN_DESCRIPTOR) - - - The descriptor specified was not found. The statement you are - trying to use has not been prepared. (SQLSTATE 33000) - - - - - - -241 (ECPG_INVALID_DESCRIPTOR_INDEX) - - - The descriptor index specified was out of range. (SQLSTATE - 07009) - - - - - - -242 (ECPG_UNKNOWN_DESCRIPTOR_ITEM) - - - An invalid descriptor item was requested. (This is an internal - error.) (SQLSTATE YE002) - - - - - - -243 (ECPG_VAR_NOT_NUMERIC) - - - During the execution of a dynamic statement, the database - returned a numeric value and the host variable was not numeric. - (SQLSTATE 07006) - - - - - - -244 (ECPG_VAR_NOT_CHAR) - - - During the execution of a dynamic statement, the database - returned a non-numeric value and the host variable was numeric. - (SQLSTATE 07006) - - - - - - -284 (ECPG_INFORMIX_SUBSELECT_NOT_ONE) - - - A result of the subquery is not single row (Informix - compatibility mode). (SQLSTATE 21000) - - - - - - -400 (ECPG_PGSQL) - - - Some error caused by the PostgreSQL - server. The message contains the error message from the - PostgreSQL server. - - - - - - -401 (ECPG_TRANS) - - - The PostgreSQL server signaled that - we cannot start, commit, or rollback the transaction. - (SQLSTATE 08007) - - - - - - -402 (ECPG_CONNECT) - - - The connection attempt to the database did not succeed. - (SQLSTATE 08001) - - - - - - -403 (ECPG_DUPLICATE_KEY) - - - Duplicate key error, violation of unique constraint. (SQLSTATE - 23505) - - - - - - -404 (ECPG_SUBSELECT_NOT_ONE) - - - A result for the subquery is not single row. (SQLSTATE 21000) - - - - - - - -600 (ECPG_WARNING_UNRECOGNIZED) - - - An unrecognized warning was received from the server. - - - - - - -601 (ECPG_WARNING_QUERY_IGNORED) - - - Current transaction is aborted. Queries are ignored until the - end of the transaction block. - - - -]]> - - - -602 (ECPG_WARNING_UNKNOWN_PORTAL) - - - An invalid cursor name was specified. (SQLSTATE 34000) - - - - - - -603 (ECPG_WARNING_IN_TRANSACTION) - - - Transaction is in progress. (SQLSTATE 25001) - - - - - - -604 (ECPG_WARNING_NO_TRANSACTION) - - - There is no active (in-progress) transaction. (SQLSTATE 25P01) - - - - - - -605 (ECPG_WARNING_PORTAL_EXISTS) - - - An existing cursor name was specified. (SQLSTATE 42P03) - - - - - - - - - - - Preprocessor directives - - - Including files - - - To include an external file into your embedded SQL program, use: - -EXEC SQL INCLUDE filename; - - The embedded SQL preprocessor will look for a file named - filename.h, - preprocess it, and include it in the resulting C output. Thus, - embedded SQL statements in the included file are handled correctly. - - - - Note that this is not the same as: - -#include <filename.h> - - because this file would not be subject to SQL command preprocessing. - Naturally, you can continue to use the C - #include directive to include other header - files. - - - - - The include file name is case-sensitive, even though the rest of - the EXEC SQL INCLUDE command follows the normal - SQL case-sensitivity rules. - - - - - - The #define and #undef directives - - Similar to the directive #define that is known from C, - embedded SQL has a similar concept: - -EXEC SQL DEFINE name; -EXEC SQL DEFINE name value; - - So you can define a name: - -EXEC SQL DEFINE HAVE_FEATURE; - - And you can also define constants: - -EXEC SQL DEFINE MYNUMBER 12; -EXEC SQL DEFINE MYSTRING 'abc'; - - Use undef to remove a previous definition: - -EXEC SQL UNDEF MYNUMBER; - - - - - Of course you can continue to use the C versions #define - and #undef in your embedded SQL program. The difference - is where your defined values get evaluated. If you use EXEC SQL - DEFINE then the ecpg preprocessor evaluates the defines and substitutes - the values. For example if you write: - -EXEC SQL DEFINE MYNUMBER 12; -... -EXEC SQL UPDATE Tbl SET col = MYNUMBER; - - then ecpg will already do the substitution and your C compiler will never - see any name or identifier MYNUMBER. Note that you cannot use - #define for a constant that you are going to use in an - embedded SQL query because in this case the embedded SQL precompiler is not - able to see this declaration. - - - - - ifdef, ifndef, else, elif, and endif directives - - You can use the following directives to compile code sections conditionally: - - - - EXEC SQL ifdef name; - - - Checks a name and processes subsequent lines if - name has been created with EXEC SQL define - name. - - - - - - EXEC SQL ifndef name; - - - Checks a name and processes subsequent lines if - name has not been created with - EXEC SQL define name. - - - - - - EXEC SQL else; - - - Starts processing an alternative section to a section introduced by - either EXEC SQL ifdef name or - EXEC SQL ifndef name. - - - - - - EXEC SQL elif name; - - - Checks name and starts an alternative section if - name has been created with EXEC SQL define - name. - - - - - - EXEC SQL endif; - - - Ends an alternative section. - - - - - - - - Example: - -EXEC SQL ifndef TZVAR; -EXEC SQL SET TIMEZONE TO 'GMT'; -EXEC SQL elif TZNAME; -EXEC SQL SET TIMEZONE TO TZNAME; -EXEC SQL else; -EXEC SQL SET TIMEZONE TO TZVAR; -EXEC SQL endif; - - - - - - - - Processing Embedded SQL Programs - - - Now that you have an idea how to form embedded SQL C programs, you - probably want to know how to compile them. Before compiling you - run the file through the embedded SQL - C preprocessor, which converts the - SQL statements you used to special function - calls. After compiling, you must link with a special library that - contains the needed functions. These functions fetch information - from the arguments, perform the SQL command using - the libpq interface, and put the result - in the arguments specified for output. - - - - The preprocessor program is called ecpg and is - included in a normal PostgreSQL installation. - Embedded SQL programs are typically named with an extension - .pgc. If you have a program file called - prog1.pgc, you can preprocess it by simply - calling: - -ecpg prog1.pgc - - This will create a file called prog1.c. If - your input files do not follow the suggested naming pattern, you - can specify the output file explicitly using the - option. - - - - The preprocessed file can be compiled normally, for example: - -cc -c prog1.c - - The generated C source files include header files from the - PostgreSQL installation, so if you installed - PostgreSQL in a location that is not searched by - default, you have to add an option such as - -I/usr/local/pgsql/include to the compilation - command line. - - - - To link an embedded SQL program, you need to include the - libecpg library, like so: - -cc -o myprog prog1.o prog2.o ... -lecpg - - Again, you might have to add an option like - -L/usr/local/pgsql/lib to that command line. - - - - If you manage the build process of a larger project using - make, it might be convenient to include - the following implicit rule to your makefiles: - -ECPG = ecpg - -%.c: %.pgc - $(ECPG) $< - - - - - The complete syntax of the ecpg command is - detailed in . - - - - The ecpg library is thread-safe by - default. However, you might need to use some threading - command-line options to compile your client code. - - - - - Library Functions - - - The libecpg library primarily contains - hidden functions that are used to implement the - functionality expressed by the embedded SQL commands. But there - are some functions that can usefully be called directly. Note that - this makes your code unportable. - - - - - - ECPGdebug(int on, FILE - *stream) turns on debug - logging if called with the first argument non-zero. Debug logging - is done on stream. The log contains - all SQL statements with all the input - variables inserted, and the results from the - PostgreSQL server. This can be very - useful when searching for errors in your SQL - statements. - - - - On Windows, if the ecpg libraries and an application are - compiled with different flags, this function call will crash the - application because the internal representation of the - FILE pointers differ. Specifically, - multithreaded/single-threaded, release/debug, and static/dynamic - flags should be the same for the library and all applications using - that library. - - - - - - - ECPGget_PGconn(const char *connection_name) - returns the library database connection handle identified by the given name. - If connection_name is set to NULL, the current - connection handle is returned. If no connection handle can be identified, the function returns - NULL. The returned connection handle can be used to call any other functions - from libpq, if necessary. - - - - It is a bad idea to manipulate database connection handles made from ecpg directly - with libpq routines. - - - - - - - ECPGtransactionStatus(const char *connection_name) - returns the current transaction status of the given connection identified by connection_name. - See and libpq's PQtransactionStatus() for details about the returned status codes. - - - - - - ECPGstatus(int lineno, - const char* connection_name) - returns true if you are connected to a database and false if not. - connection_name can be NULL - if a single connection is being used. - - - - - Internals diff --git a/doc/src/sgml/stylesheet-man.xsl b/doc/src/sgml/stylesheet-man.xsl index 81e875614a8..8c614ca754d 100644 --- a/doc/src/sgml/stylesheet-man.xsl +++ b/doc/src/sgml/stylesheet-man.xsl @@ -90,6 +90,50 @@ + + + + + + + + + + 0 + + + + + + + + + + + + + + + + + + + + + + + Note: + + + + + + +