Linus Tolke Michael Meskes 1996-1997 Linus Tolke 1998 Michael Meskes Transcribed 1998-02-12 <application>ecpg</application> - Embedded <acronym>SQL</acronym> in <acronym>C</acronym> This describes the embedded SQL package for Postgres. It works with C and C++. It was written by Linus Tolke (linus@epact.se) and Michael Meskes (meskes@debian.org). The package is installed with the Postgres distribution, and carries a similar license. Why Embedded <acronym>SQL</acronym>? Embedded SQL has advantages over other methods for handling SQL queries. It takes care of the tedious passing of information to and from variables in your C or C++ program. Many RDBMS packages support this embedded language. There is an ANSI standard describing how the embedded language should work. ecpg was designed to match this standard as much as possible. It is possible to port embedded SQL programs written for other RDBMS to Postgres. The Concept You write your program in C/C++ with special SQL constructs. When declaring variables to be used in SQL statements, you need to put them in a special declare section. You use a special syntax for the SQL queries. Before compiling you run the file through the embedded SQL C preprocessor and it converts the SQL statements you used to function calls with the variables used as arguments. Both query input and result output variables are passed. After compiling, you must link with a special library that contains needed functions. These functions fetch information from the arguments, perform the SQL query using the libpq interface, and put the result in the arguments specified for output. How To Use <application>ecpg</application> This section describes how to use ecpg. Preprocessor The preprocessor is called ecpg. After installation it resides in the Postgres bin/ directory. Library The ecpg library is called libecpg.a or libecpg.so. Additionally, the library uses the libpq library for communication to the Postgres server. You will have to link your program using -lecpg -lpq. The library has some methods that are hidden but may prove useful. ECPGdebug(int on, FILE *stream) turns on debug logging if called with the first argument non-zero. Debug logging is done on stream. Most SQL statement log their arguments and results. The most important function , ECPGdo, logs all SQL statements with both the expanded string, i.e. the string with all the input variables inserted, and the result from the Postgres server. This can be very useful when searching for errors in your SQL statements. ECPGstatus() This method returns TRUE if we are connected to a database and FALSE if not. Error handling To detect errors from the Postgres server, include a line like: exec sql include sqlca; in the include section of your file. This will define a struct and a variable with the name sqlca as follows: struct sqlca { char sqlcaid[8]; long sqlabc; long sqlcode; struct { int sqlerrml; char sqlerrmc[70]; } sqlerrm; char sqlerrp[8]; long sqlerrd[6]; /* 0: empty */ /* 1: OID of processed tuple if applicable */ /* 2: number of rows processed in an INSERT, UPDATE */ /* or DELETE statement */ /* 3: empty */ /* 4: empty */ /* 5: empty */ char sqlwarn[8]; /* 0: set to 'W' if at least one other is 'W' */ /* 1: if 'W' at least one character string */ /* value was truncated when it was */ /* stored into a host variable. */ /* 2: empty */ /* 3: empty */ /* 4: empty */ /* 5: empty */ /* 6: empty */ /* 7: empty */ char sqlext[8]; } sqlca; If an error occurred in the last SQL statement. sqlca.sqlcode will be non-zero. If sqlca.sqlcode is less that 0, this is a serious error, like the database definition does not match the query. If it is greater than 0, it is a normal error like the table did not contain the requested row. sqlca.sqlerrm.sqlerrmc will contain a string that describes the error. The string ends with the line number in the source file. List of errors that can occur: -12, Out of memory in line %d. Should not normally occur. This indicates your virtual memory is exhausted. -200, Unsupported type %s on line %d. Should not normally occur. This 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. -201, Too many arguments line %d. This means that Postgres has returned more arguments than we have matching variables. Perhaps you have forgotten a couple of the host variables in the INTO :var1,:var2-list. -202, Too few arguments line %d. This means that Postgres has returned fewer arguments than we have host variables. Perhaps you have too many host variables in the INTO :var1,:var2-list. -203, Too many matches line %d. This means the query has returned several rows but the variables specified are not arrays. The SELECT command was not unique. -204, Not correctly formatted int type: %s line %d. This means the host variable is of type int and the field in the Postgres database is of another type and contains a value that cannot be interpreted as an int. The library uses strtol() for this conversion. -205, Not correctly formatted unsigned type: %s line %d. This means the host variable is of type unsigned int and the field in the Postgres database is of another type and contains a value that cannot be interpreted as an unsigned int. The library uses strtoul() for this conversion. -206, Not correctly formatted floating point type: %s line %d. This means the host variable is of type float and the field in the Postgres database is of another type and contains a value that cannot be interpreted as a float. The library uses strtod() for this conversion. -207, Unable to convert %s to bool on line %d. This means the host variable is of type bool and the field in the Postgres database is neither 't' nor 'f'. -208, Empty query line %d. Postgres returned PGRES_EMPTY_QUERY, probably because the query indeed was empty. -220, No such connection %s in line %d. The program tried to access a connection that does not exist. -221, Not connected in line %d. The program tried to access a connection that does exist but is not open. -230, Invalid statement name %s in line %d. The statement you are trying to use has not been prepared. -400, Postgres error: %s line %d. Some Postgres error. The message contains the error message from the Postgres backend. -401, Error in transaction processing line %d. Postgres signaled that we cannot start, commit or rollback the transaction. -402, connect: could not open database %s. The connect to the database did not work. 100, Data not found line %d. This is a normal error that tells you that what you are querying cannot be found or you are at the end of the cursor. Limitations What will never be included and why it cannot be done. Oracle's single tasking Oracle version 7.0 on AIX 3 uses OS-supported locks in shared memory that allow an application designer to link an application in a single tasking way. Instead of starting one client process per application process, both the database part and the application part run in the same process. In later versions of Oracle this is no longer supported. This would require a total redesign of the Postgres access model and the performance gain does not justify the effort. Porting From Other <acronym>RDBMS</acronym> Packages The design of ecpg follows the SQL standard. Porting from a standard RDBMS should not be a problem. Unfortunately there is no such thing as a standard RDBMS. Therefore ecpg tries to understand syntax extensions as long as they do not create conflicts with the standard. The following list shows all the known incompatibilities. If you find one not listed please notify Michael Meskes. Note, however, that we list only incompatibilities from a precompiler of another RDBMS to ecpg and not ecpg features that these RDBMS do not support. Syntax of FETCH The standard syntax for FETCH is: FETCH [direction] [amount] IN|FROM cursor. ORACLE, however, does not use the keywords IN or FROM. This feature cannot be added since it would create parsing conflicts. For the Developer This section explain how ecpg works internally. It contains valuable information to help users understand how to use ecpg. ToDo List This version of the preprocessor has some flaws: Library functions to_date et al. does not exist. However, Postgres has some good conversion routines so you probably won't miss them. Structures and unions Structures and unions have to be defined in the declare section. Missing statements The following statements are not implemented thus far: exec sql allocate exec sql deallocate SQLSTATE message 'no data found' The error message for no data in: exec sql insert select from statement has to be 100. sqlwarn[6] sqlwarn[6] should be W if the PRECISION or SCALE value specified in a SET DESCRIPTOR statement was ignored. The Preprocessor The first four lines written by ecpg to the output are fixed lines. Two are comments and two are include lines necessary to interface to the library. Then the preprocessor reads through the file and writes output. Normally it just echoes everything to the output. When it sees an EXEC SQL statement, it intervenes and changes it. The EXEC SQL statement can be one of these: Declare sections Declare sections begin with: exec sql begin declare section; and end with: exec sql end declare section; In this section only variable declarations are allowed. Every variable declared within this section is stored in a list of variables indexed by name together with its corresponding type. In particular the definition of a structure or union also must be listed inside a declare section. Otherwise ecpg cannot handle these types since it does not know the definition. The declaration is also echoed to the file to make it a normal C variable. The special types VARCHAR and VARCHAR2 are 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; Include statements An include statement looks like: exec sql include filename; Note that this is NOT the same as: #include <filename.h> Instead the file specified is parsed by ecpg so the contents of the file are included in the resulting C code. This way you are able to specify EXEC SQL commands in an include file. Connect statement A connect statement looks like: exec sql connect to connection target; It creates a connection to the specified database. The connection target can be specified in the following ways: dbname[@server][:port][as connection name][user user name] tcp:postgresql://server[:port][/dbname][as connection name][user user name] unix:postgresql://server[:port][/dbname][as connection name][user user name] character variable[as connection name][user user name] character string[as connection name][user] default user There are also different ways to specify the user name: userid userid/password userid identified by password userid using password Finally, the userid and password may be a constant text, a character variable, or a character string. Disconnect statements A disconnect statement looks like: exec sql disconnect [connection target]; It closes the connection to the specified database. The connection target can be specified in the following ways: connection name default current all Open cursor statement An open cursor statement looks like: exec sql open cursor; and is not copied to the output. Instead, the cursor's DECLARE command is used because it opens the cursor as well. Commit statement A commit statement looks like: exec sql commit; Rollback statement A rollback statement looks like: exec sql rollback; Other statements Other SQL statements are used by starting with exec sql and ending with ;. Everything in between is treated as an SQL statement and parsed for variable substitution. Variable substitution occurs when a symbol starts with a colon (:). The variable with that name is looked up among the variables that were previously declared within a declare section. Depending on whether the variable is being use for input or output, a pointer to the variable is output to allow access by the function. For every variable that is part of the SQL query, the function gets other arguments: The type as a special symbol. A pointer to the value or a pointer to the pointer. The size of the variable if it is a char or varchar. The number of elements in the array (for array fetches). The offset to the next element in the array (for array fetches). The type of the indicator variable as a special symbol. A pointer to the value of the indicator variable or a pointer to the pointer of the indicator variable. 0. Number of elements in the indicator array (for array fetches). The offset to the next element in the indicator array (for array fetches). A Complete Example Here is a complete example describing the output of the preprocessor of a file foo.pgc: exec sql begin declare section; int index; int result; exec sql end declare section; ... exec sql select res into :result from mytable where index = :index; is translated into: /* Processed by ecpg (2.6.0) */ /* These two include files are added by the preprocessor */ #include <ecpgtype.h>; #include <ecpglib.h>; /* exec sql begin declare section */ #line 1 "foo.pgc" int index; int result; /* exec sql end declare section */ ... ECPGdo(__LINE__, NULL, "select res from mytable where index = ? ", ECPGt_int,&(index),1L,1L,sizeof(int), ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_EOIT, ECPGt_int,&(result),1L,1L,sizeof(int), ECPGt_NO_INDICATOR, NULL , 0L, 0L, 0L, ECPGt_EORT); #line 147 "foo.pgc" (The indentation in this manual is added for readability and not something the preprocessor does.) The Library The most important function in the library is ECPGdo. It takes a variable number of arguments. Hopefully there are no computers that limit the number of variables that can be accepted by a varargs() function. This can easily add up to 50 or so arguments. The arguments are: A line number This is a line number of the original line; used in error messages only. A string This is the SQL query that is to be issued. It is modified by the input variables, i.e. the variables that where not known at compile time but are to be entered in the query. Where the variables should go the string contains ?. Input variables As described in the section about the preprocessor, every input variable gets ten arguments. ECPGt_EOIT An enum telling that there are no more input variables. Output variables As described in the section about the preprocessor, every input variable gets ten arguments. These variables are filled by the function. ECPGt_EORT An enum telling that there are no more variables. All SQL statements are performed in one transaction unless you issue a commit transaction. To accomplish this auto-transaction behavior, the first statement and the first statement after a commit or rollback always begins a new transaction. To disable this feature, use the command-line option.