ECPG - Embedded SQL in Cembedded SQLin CCECPG
This chapter describes the embedded SQL package
for PostgreSQL. It was written by
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.
This documentation is quite incomplete. But since this
interface is standardized, additional information can be found in
many resources about SQL.
The Concept
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
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.
Embedded SQL has advantages over other methods
for handling SQL commands from C code. First, it
takes care of the tedious passing of information to and from
variables in your C program. Second, the SQL
code in the program is checked at build time for syntactical
correctness. Third, embedded SQL in C is
specified in the SQL standard and supported by
many other SQL database systems. The
PostgreSQL> implementation is designed to match this
standard as much as possible, and it is usually possible to port
embedded SQL programs written for other SQL
databases to PostgreSQL with relative
ease.
As already stated, programs written for the embedded
SQL interface are normal C programs with special
code inserted to perform database-related actions. This special
code always has the form:
EXEC SQL ...;
These statements syntactically take the place of a C statement.
Depending on the particular statement, they can appear at the
global level or within a function. Embedded
SQL statements follow the case-sensitivity rules
of normal SQL code, and not those of C.
The following sections explain all the embedded SQL statements.
Connecting to the Database Server
One connects to a database using the following statement:
EXEC SQL CONNECT TO targetAS connection-nameUSER user-name;
The target can be specified in the
following ways:
dbname>@hostname>:port>tcp:postgresql://hostname>:port>/dbname>?options>unix:postgresql://hostname>:port>/dbname>?options>
an SQL string literal containing one of the above forms
a reference to a character variable containing one of the above forms (see examples)
DEFAULT
If you specify the connection target literally (that is, not
through a variable reference) and you don't quote the value, then
the case-insensitivity rules of normal SQL are applied. In that
case you can also double-quote the individual parameters separately
as needed. In practice, it is probably less error-prone to use a
(single-quoted) string literal or a variable reference. The
connection target DEFAULT initiates a connection
to the default database under the default user name. No separate
user name or connection name can be specified in that case.
There are also different ways to specify the user name:
usernameusername/passwordusername IDENTIFIED BY passwordusername USING password
As above, the parameters username and
password can be an SQL identifier, an
SQL string literal, or a reference to a character variable.
The connection-name is used to handle
multiple connections in one program. It can be omitted if a
program uses only one connection. The most recently opened
connection becomes the current connection, which is used by default
when an SQL statement is to be executed (see later in this
chapter).
Here are some examples of CONNECT statements:
EXEC SQL CONNECT TO mydb@sql.mydomain.com;
EXEC SQL CONNECT TO unix:postgresql://sql.mydomain.com/mydb AS myconnection USER john;
EXEC SQL BEGIN DECLARE SECTION;
const char *target = "mydb@sql.mydomain.com";
const char *user = "john";
EXEC SQL END DECLARE SECTION;
...
EXEC SQL CONNECT TO :target USER :user;
The last form makes use of the variant referred to above as
character variable reference. You will see in later sections how C
variables can be used in SQL statements when you prefix them with a
colon.
Be advised that the format of the connection target is not
specified in the SQL standard. So if you want to develop portable
applications, you might want to use something based on the last
example above to encapsulate the connection target string
somewhere.
Closing a Connection
To close a connection, use the following statement:
EXEC SQL DISCONNECT connection;
The connection can be specified
in the following ways:
connection-nameDEFAULTCURRENTALL
If no connection name is specified, the current connection is
closed.
It is good style that an application always explicitly disconnect
from every connection it opened.
Running SQL Commands
Any SQL command can be run from within an embedded SQL application.
Below are some examples of how to do that.
Creating a table:
EXEC SQL CREATE TABLE foo (number integer, ascii char(16));
EXEC SQL CREATE UNIQUE INDEX num1 ON foo(number);
EXEC SQL COMMIT;
Inserting rows:
EXEC SQL INSERT INTO foo (number, ascii) VALUES (9999, 'doodad');
EXEC SQL COMMIT;
Deleting rows:
EXEC SQL DELETE FROM foo WHERE number = 9999;
EXEC SQL COMMIT;
Single-row select:
EXEC SQL SELECT foo INTO :FooBar FROM table1 WHERE ascii = 'doodad';
Select using cursors:
EXEC SQL DECLARE foo_bar CURSOR FOR
SELECT number, ascii FROM foo
ORDER BY ascii;
EXEC SQL OPEN foo_bar;
EXEC SQL FETCH foo_bar INTO :FooBar, DooDad;
...
EXEC SQL CLOSE foo_bar;
EXEC SQL COMMIT;
Updates:
EXEC SQL UPDATE foo
SET ascii = 'foobar'
WHERE number = 9999;
EXEC SQL COMMIT;
The tokens of the form
:something are
host variables, that is, they refer to
variables in the C program. They are explained in .
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.
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.
Using Host Variables
In you saw how you can execute SQL
statements from an embedded SQL program. Some of those statements
only used fixed values and did not provide a way to insert
user-supplied values into statements or have the program process
the values returned by the query. Those kinds of statements are
not really useful in real applications. This section explains in
detail how you can pass data between your C program and the
embedded SQL statements using a simple mechanism called
host variables. In an embedded SQL program we
consider the SQL statements to be guests in the C
program code which is the host language. Therefore
the variables of the C program are called host
variables.
Overview
Passing data between the C program and the SQL statements is
particularly simple in embedded SQL. Instead of having the
program paste the data into the statement, which entails various
complications, such as properly quoting the value, you can simply
write the name of a C variable into the SQL statement, prefixed by
a colon. For example:
EXEC SQL INSERT INTO sometable VALUES (:v1, 'foo', :v2);
This statements refers to two C variables named
v1 and v2 and also uses a
regular SQL string literal, to illustrate that you are not
restricted to use one kind of data or the other.
This style of inserting C variables in SQL statements works
anywhere a value expression is expected in an SQL statement.
Declare Sections
To pass data from the program to the database, for example as
parameters in a query, or to pass data from the database back to
the program, the C variables that are intended to contain this
data need to be declared in specially marked sections, so the
embedded SQL preprocessor is made aware of them.
This section starts with:
EXEC SQL BEGIN DECLARE SECTION;
and ends with:
EXEC SQL END DECLARE SECTION;
Between those lines, there must be normal C variable declarations,
such as:
int x = 4;
char foo[16], bar[16];
As you can see, you can optionally assign an initial value to the variable.
The variable's scope is determined by the location of its declaring
section within the program.
You can also declare variables with the following syntax which implicitly
creates a declare section:
EXEC SQL int i = 4;
You can have as many declare sections in a program as you like.
The declarations are also echoed to the output file as normal C
variables, so there's no need to declare them again. Variables
that are not intended to be used in SQL commands can be declared
normally outside these special sections.
The definition of a structure or union also must be listed inside
a DECLARE> section. Otherwise the preprocessor cannot
handle these types since it does not know the definition.
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.
SELECT INTO and FETCH INTO
Now you should be able to pass data generated by your program into
an SQL command. But how do you retrieve the results of a query?
For that purpose, embedded SQL provides special variants of the
usual commands SELECT and
FETCH. These commands have a special
INTO clause that specifies which host variables
the retrieved values are to be stored in.
Here is an example:
/*
* assume this table:
* CREATE TABLE test1 (a int, b varchar(50));
*/
EXEC SQL BEGIN DECLARE SECTION;
int v1;
VARCHAR v2;
EXEC SQL END DECLARE SECTION;
...
EXEC SQL SELECT a, b INTO :v1, :v2 FROM test;
So the INTO clause appears between the select
list and the FROM clause. The number of
elements in the select list and the list after
INTO (also called the target list) must be
equal.
Here is an example using the command FETCH:
EXEC SQL BEGIN DECLARE SECTION;
int v1;
VARCHAR v2;
EXEC SQL END DECLARE SECTION;
...
EXEC SQL DECLARE foo CURSOR FOR SELECT a, b FROM test;
...
do {
...
EXEC SQL FETCH NEXT FROM foo INTO :v1, :v2;
...
} while (...);
Here the INTO clause appears after all the
normal clauses.
Both of these methods only allow retrieving one row at a time. If
you need to process result sets that potentially contain more than
one row, you need to use a cursor, as shown in the second example.
Indicators
The examples above do not handle null values. In fact, the
retrieval examples will raise an error if they fetch a null value
from the database. To be able to pass null values to the database
or retrieve null values from the database, you need to append a
second host variable specification to each host variable that
contains data. This second host variable is called the
indicator and contains a flag that tells
whether the datum is null, in which case the value of the real
host variable is ignored. Here is an example that handles the
retrieval of null values correctly:
EXEC SQL BEGIN DECLARE SECTION;
VARCHAR val;
int val_ind;
EXEC SQL END DECLARE SECTION:
...
EXEC SQL SELECT b INTO :val :val_ind FROM test1;
The indicator variable val_ind will be zero if
the value was not null, and it will be negative if the value was
null.
The indicator has another function: if the indicator value is
positive, it means that the value is not null, but it was
truncated when it was stored in the host variable.
Dynamic SQL
In many cases, the particular SQL statements that an application
has to execute are known at the time the application is written.
In some cases, however, the SQL statements are composed at run time
or provided by an external source. In these cases you cannot embed
the SQL statements directly into the C source code, but there is a
facility that allows you to call arbitrary SQL statements that you
provide in a string variable.
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 (...);";
EXEC SQL END DECLARE SECTION;
EXEC SQL EXECUTE IMMEDIATE :stmt;
You cannot execute statements that retrieve data (e.g.,
SELECT) this way.
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(?, ?);";
EXEC SQL END DECLARE SECTION;
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:
?";
int v1, v2;
VARCHAR v3;
EXEC SQL END DECLARE SECTION;
EXEC SQL PREPARE mystmt FROM :stmt;
...
EXEC SQL EXECUTE mystmt INTO v1, v2, v3 USING 37;
]]>
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:
EXEC SQL DEALLOCATE PREPARE name;
pgtypes library
The pgtypes library maps PostgreSQL database
types to C equivalents that can be used in C programs. It also offers
functions to do basic calculations with those types within C, i.e., without
the help of the PostgreSQL server. See the
following example:
The numeric type
The numeric type offers to do calculations with arbitrary precision. See
for the equivalent type in the
PostgreSQL> server. Because of the arbitrary precision this
variable needs to be able to expand and shrink dynamically. That's why you
can only create numeric variables on the heap, by means of the
PGTYPESnumeric_new> and PGTYPESnumeric_free>
functions. The decimal type, which is similar but limited in precision,
can be created on the stack as well as on the heap.
The following functions can be used to work with the numeric type:
PGTYPESnumeric_new
Request a pointer to a newly allocated numeric variable.
numeric *PGTYPESnumeric_new(void);
PGTYPESnumeric_free
Free a numeric type, release all of its memory.
void PGTYPESnumeric_free(numeric *var);
PGTYPESnumeric_from_asc
Parse a numeric type from its string notation.
numeric *PGTYPESnumeric_from_asc(char *str, char **endptr);
Valid formats are for example:
-2,
.794,
+3.44,
592.49E07 or
-32.84e-4.
If the value could be parsed successfully, a valid pointer is returned,
else the NULL pointer. At the moment ECPG always parses the complete
string and so it currently does not support to store the address of the
first invalid character in *endptr. You can safely
set endptr to NULL.
PGTYPESnumeric_to_asc
Returns a pointer to a string allocated by malloc that contains the string
representation of the numeric type num.
char *PGTYPESnumeric_to_asc(numeric *num, int dscale);
The numeric value will be printed with dscale decimal
digits, with rounding applied if necessary.
PGTYPESnumeric_add
Add two numeric variables into a third one.
int PGTYPESnumeric_add(numeric *var1, numeric *var2, numeric *result);
The function adds the variables var1 and
var2 into the result variable
result.
The function returns 0 on success and -1 in case of error.
PGTYPESnumeric_sub
Subtract two numeric variables and return the result in a third one.
int PGTYPESnumeric_sub(numeric *var1, numeric *var2, numeric *result);
The function subtracts the variable var2 from
the variable var1. The result of the operation is
stored in the variable result.
The function returns 0 on success and -1 in case of error.
PGTYPESnumeric_mul
Multiply two numeric variables and return the result in a third one.
int PGTYPESnumeric_mul(numeric *var1, numeric *var2, numeric *result);
The function multiplies the variables var1 and
var2. The result of the operation is stored in the
variable result.
The function returns 0 on success and -1 in case of error.
PGTYPESnumeric_div
Divide two numeric variables and return the result in a third one.
int PGTYPESnumeric_div(numeric *var1, numeric *var2, numeric *result);
The function divides the variables var1 by
var2. The result of the operation is stored in the
variable result.
The function returns 0 on success and -1 in case of error.
PGTYPESnumeric_cmp
Compare two numeric variables.
int PGTYPESnumeric_cmp(numeric *var1, numeric *var2)
This function compares two numeric variables. In case of error,
INT_MAX is returned. On success, the function
returns one of three possible results:
1, if var1> is bigger than var2>
-1, if var1> is smaller than var2>
0, if var1> and var2> are equal
PGTYPESnumeric_from_int
Convert an int variable to a numeric variable.
int PGTYPESnumeric_from_int(signed int int_val, numeric *var);
This function accepts a variable of type signed int and stores it
in the numeric variable var>. Upon success, 0 is returned and
-1 in case of a failure.
PGTYPESnumeric_from_long
Convert a long int variable to a numeric variable.
int PGTYPESnumeric_from_long(signed long int long_val, numeric *var);
This function accepts a variable of type signed long int and stores it
in the numeric variable var>. Upon success, 0 is returned and
-1 in case of a failure.
PGTYPESnumeric_copy
Copy over one numeric variable into another one.
int PGTYPESnumeric_copy(numeric *src, numeric *dst);
This function copies over the value of the variable that
src points to into the variable that dst>
points to. It returns 0 on success and -1 if an error occurs.
PGTYPESnumeric_from_double
Convert a variable of type double to a numeric.
int PGTYPESnumeric_from_double(double d, numeric *dst);
This function accepts a variable of type double and stores the result
in the variable that dst> points to. It returns 0 on success
and -1 if an error occurs.
PGTYPESnumeric_to_double
Convert a variable of type numeric to double.
int PGTYPESnumeric_to_double(numeric *nv, double *dp)
The function converts the numeric value from the variable that
nv> points to into the double variable that dp> points
to. It returns 0 on success and -1 if an error occurs, including
overflow. On overflow, the global variable errno> will be set
to PGTYPES_NUM_OVERFLOW> additionally.
PGTYPESnumeric_to_int
Convert a variable of type numeric to int.
int PGTYPESnumeric_to_int(numeric *nv, int *ip);
The function converts the numeric value from the variable that
nv> points to into the integer variable that ip>
points to. It returns 0 on success and -1 if an error occurs, including
overflow. On overflow, the global variable errno> will be set
to PGTYPES_NUM_OVERFLOW> additionally.
PGTYPESnumeric_to_long
Convert a variable of type numeric to long.
int PGTYPESnumeric_to_long(numeric *nv, long *lp);
The function converts the numeric value from the variable that
nv> points to into the long integer variable that
lp> points to. It returns 0 on success and -1 if an error
occurs, including overflow. On overflow, the global variable
errno> will be set to PGTYPES_NUM_OVERFLOW>
additionally.
PGTYPESnumeric_to_decimal
Convert a variable of type numeric to decimal.
int PGTYPESnumeric_to_decimal(numeric *src, decimal *dst);
The function converts the numeric value from the variable that
src> points to into the decimal variable that
dst> points to. It returns 0 on success and -1 if an error
occurs, including overflow. On overflow, the global variable
errno> will be set to PGTYPES_NUM_OVERFLOW>
additionally.
PGTYPESnumeric_from_decimal
Convert a variable of type decimal to numeric.
int PGTYPESnumeric_from_decimal(decimal *src, numeric *dst);
The function converts the decimal value from the variable that
src> points to into the numeric variable that
dst> points to. It returns 0 on success and -1 if an error
occurs. Since the decimal type is implemented as a limited version of
the numeric type, overflow cannot occur with this conversion.
The date type
The date type in C enables your programs to deal with data of the SQL type
date. See for the equivalent type in the
PostgreSQL> server.
The following functions can be used to work with the date type:
PGTYPESdate_from_timestamp
Extract the date part from a timestamp.
date PGTYPESdate_from_timestamp(timestamp dt);
The function receives a timestamp as its only argument and returns the
extracted date part from this timestamp.
PGTYPESdate_from_asc
Parse a date from its textual representation.
date PGTYPESdate_from_asc(char *str, char **endptr);
The function receives a C char* string str> and a pointer to
a C char* string endptr>. At the moment ECPG always parses
the complete string and so it currently does not support to store the
address of the first invalid character in *endptr.
You can safely set endptr to NULL.
Note that the function always assumes MDY-formatted dates and there is
currently no variable to change that within ECPG.
shows the allowed input formats.
Valid input formats for PGTYPESdate_from_ascInputResultJanuary 8, 1999January 8, 19991999-01-08January 8, 19991/8/1999January 8, 19991/18/1999January 18, 199901/02/03February 1, 20031999-Jan-08January 8, 1999Jan-08-1999January 8, 199908-Jan-1999January 8, 199999-Jan-08January 8, 199908-Jan-99January 8, 199908-Jan-06January 8, 2006Jan-08-99January 8, 199919990108ISO 8601; January 8, 1999990108ISO 8601; January 8, 19991999.008year and day of yearJ2451187Julian dayJanuary 8, 99 BCyear 99 before the Common Era
PGTYPESdate_to_asc
Return the textual representation of a date variable.
char *PGTYPESdate_to_asc(date dDate);
The function receives the date dDate> as its only parameter.
It will output the date in the form 1999-01-18>, i.e., in the
YYYY-MM-DD> format.
PGTYPESdate_julmdy
Extract the values for the day, the month and the year from a variable
of type date.
void PGTYPESdate_julmdy(date d, int *mdy);
The function receives the date d> and a pointer to an array
of 3 integer values mdy>. The variable name indicates
the sequential order: mdy[0]> will be set to contain the
number of the month, mdy[1]> will be set to the value of the
day and mdy[2]> will contain the year.
PGTYPESdate_mdyjul
Create a date value from an array of 3 integers that specify the
day, the month and the year of the date.
void PGTYPESdate_mdyjul(int *mdy, date *jdate);
The function receives the array of the 3 integers (mdy>) as
its first argument and as its second argument a pointer to a variable
of type date that should hold the result of the operation.
PGTYPESdate_dayofweek
Return a number representing the day of the week for a date value.
int PGTYPESdate_dayofweek(date d);
The function receives the date variable d> as its only
argument and returns an integer that indicates the day of the week for
this date.
0 - Sunday
1 - Monday
2 - Tuesday
3 - Wednesday
4 - Thursday
5 - Friday
6 - Saturday
PGTYPESdate_today
Get the current date.
void PGTYPESdate_today(date *d);
The function receives a pointer to a date variable (d>)
that it sets to the current date.
PGTYPESdate_fmt_asc
Convert a variable of type date to its textual representation using a
format mask.
int PGTYPESdate_fmt_asc(date dDate, char *fmtstring, char *outbuf);
The function receives the date to convert (dDate>), the
format mask (fmtstring>) and the string that will hold the
textual representation of the date (outbuf>).
On success, 0 is returned and a negative value if an error occurred.
The following literals are the field specifiers you can use:
dd - The number of the day of the month.
mm - The number of the month of the year.
yy - The number of the year as a two digit number.
yyyy - The number of the year as a four digit number.
ddd - The name of the day (abbreviated).
mmm - The name of the month (abbreviated).
All other characters are copied 1:1 to the output string.
indicates a few possible formats. This will give
you an idea of how to use this function. All output lines are based on
the same date: November 23, 1959.
PGTYPESdate_defmt_asc
Use a format mask to convert a C char* string to a value of type
date.
int PGTYPESdate_defmt_asc(date *d, char *fmt, char *str);
The function receives a pointer to the date value that should hold the
result of the operation (d>), the format mask to use for
parsing the date (fmt>) and the C char* string containing
the textual representation of the date (str>). The textual
representation is expected to match the format mask. However you do not
need to have a 1:1 mapping of the string to the format mask. The
function only analyzes the sequential order and looks for the literals
yy or yyyy that indicate the
position of the year, mm to indicate the position of
the month and dd to indicate the position of the
day.
indicates a few possible formats. This will give
you an idea of how to use this function.
Valid input formats for rdefmtdateFormatStringResultddmmyy21-2-541954-02-21ddmmyy2-12-541954-12-02ddmmyy201119541954-11-20ddmmyy1304641964-04-13mmm.dd.yyyyMAR-12-19671967-03-12yy/mm/dd1954, February 3rd1954-02-03mmm.dd.yyyy0412691969-04-12yy/mm/ddIn the year 2525, in the month of July, mankind will be alive on the 28th day2525-07-28dd-mm-yyI said on the 28th of July in the year 25252525-07-28mmm.dd.yyyy9/14/581958-09-14yy/mm/dd47/03/291947-03-29mmm.dd.yyyyoct 28 19751975-10-28mmddyyNov 14th, 19851985-11-14
The timestamp type
The timestamp type in C enables your programs to deal with data of the SQL
type timestamp. See for the equivalent
type in the PostgreSQL> server.
The following functions can be used to work with the timestamp type:
PGTYPEStimestamp_from_asc
Parse a timestamp from its textual representation into a timestamp
variable.
timestamp PGTYPEStimestamp_from_asc(char *str, char **endptr);
The function receives the string to parse (str>) and a
pointer to a C char* (endptr>).
At the moment ECPG always parses
the complete string and so it currently does not support to store the
address of the first invalid character in *endptr.
You can safely set endptr to NULL.
The function returns the parsed timestamp on success. On error,
PGTYPESInvalidTimestamp is returned and errno> is
set to PGTYPES_TS_BAD_TIMESTAMP>. See for important notes on this value.
In general, the input string can contain any combination of an allowed
date specification, a whitespace character and an allowed time
specification. Note that timezones are not supported by ECPG. It can
parse them but does not apply any calculation as the
PostgreSQL> server does for example. Timezone
specifiers are silently discarded.
contains a few examples for input strings.
Valid input formats for PGTYPEStimestamp_from_ascInputResult1999-01-08 04:05:061999-01-08 04:05:06January 8 04:05:06 1999 PST1999-01-08 04:05:061999-Jan-08 04:05:06.789-81999-01-08 04:05:06.789 (time zone specifier ignored)J2451187 04:05-08:001999-01-08 04:05:00 (time zone specifier ignored)
PGTYPEStimestamp_to_asc
Converts a date to a C char* string.
char *PGTYPEStimestamp_to_asc(timestamp tstamp);
The function receives the timestamp tstamp> as
its only argument and returns an allocated string that contains the
textual representation of the timestamp.
PGTYPEStimestamp_current
Retrieve the current timestamp.
void PGTYPEStimestamp_current(timestamp *ts);
The function retrieves the current timestamp and saves it into the
timestamp variable that ts> points to.
PGTYPEStimestamp_fmt_asc
Convert a timestamp variable to a C char* using a format mask.
int PGTYPEStimestamp_fmt_asc(timestamp *ts, char *output, int str_len, char *fmtstr);
The function receives a pointer to the timestamp to convert as its
first argument (ts>), a pointer to the output buffer
(output>), the maximal length that has been allocated for
the output buffer (str_len) and the format mask to
use for the conversion (fmtstr).
Upon success, the function returns 0 and a negative value if an
error occurred.
You can use the following format specifiers for the format mask. The
format specifiers are the same ones that are used in the
strftime> function in libc. Any
non-format specifier will be copied into the output buffer.
%A - is replaced by national representation of
the full weekday name.
%a - is replaced by national representation of
the abbreviated weekday name.
%B - is replaced by national representation of
the full month name.
%b - is replaced by national representation of
the abbreviated month name.
%C - is replaced by (year / 100) as decimal
number; single digits are preceded by a zero.
%c - is replaced by national representation of
time and date.
%D - is equivalent to
%m/%d/%y.
%d - is replaced by the day of the month as a
decimal number (01-31).
%E*%O* - POSIX locale
extensions. The sequences
%Ec%EC%Ex%EX%Ey%EY%Od%Oe%OH%OI%Om%OM%OS%Ou%OU%OV%Ow%OW%Oy
are supposed to provide alternative representations.
Additionally %OB implemented to represent
alternative months names (used standalone, without day mentioned).
%e - is replaced by the day of month as a decimal
number (1-31); single digits are preceded by a blank.
%F - is equivalent to %Y-%m-%d.
%G - is replaced by a year as a decimal number
with century. This year is the one that contains the greater part of
the week (Monday as the first day of the week).
%g - is replaced by the same year as in
%G, but as a decimal number without century
(00-99).
%H - is replaced by the hour (24-hour clock) as a
decimal number (00-23).
%h - the same as %b.
%I - is replaced by the hour (12-hour clock) as a
decimal number (01-12).
%j - is replaced by the day of the year as a
decimal number (001-366).
%k - is replaced by the hour (24-hour clock) as a
decimal number (0-23); single digits are preceded by a blank.
%l - is replaced by the hour (12-hour clock) as a
decimal number (1-12); single digits are preceded by a blank.
%M - is replaced by the minute as a decimal
number (00-59).
%m - is replaced by the month as a decimal number
(01-12).
%n - is replaced by a newline.
%O* - the same as %E*.
%p - is replaced by national representation of
either "ante meridiem" or "post meridiem" as appropriate.
%R - is equivalent to %H:%M.
%r - is equivalent to %I:%M:%S
%p.
%S - is replaced by the second as a decimal
number (00-60).
%s - is replaced by the number of seconds since
the Epoch, UTC.
%T - is equivalent to %H:%M:%S%t - is replaced by a tab.
%U - is replaced by the week number of the year
(Sunday as the first day of the week) as a decimal number (00-53).
%u - is replaced by the weekday (Monday as the
first day of the week) as a decimal number (1-7).
%V - is replaced by the week number of the year
(Monday as the first day of the week) as a decimal number (01-53).
If the week containing January 1 has four or more days in the new
year, then it is week 1; otherwise it is the last week of the
previous year, and the next week is week 1.
%v - is equivalent to
%e-%b-%Y.
%W - is replaced by the week number of the year
(Monday as the first day of the week) as a decimal number (00-53).
%w - is replaced by the weekday (Sunday as the
first day of the week) as a decimal number (0-6).
%X - is replaced by national representation of
the time.
%x - is replaced by national representation of
the date.
%Y - is replaced by the year with century as a
decimal number.
%y - is replaced by the year without century as a
decimal number (00-99).
%Z - is replaced by the time zone name.
%z - is replaced by the time zone offset from
UTC; a leading plus sign stands for east of UTC, a minus sign for
west of UTC, hours and minutes follow with two digits each and no
delimiter between them (common form for RFC 822 date headers).
%+ - is replaced by national representation of
the date and time.
%-* - GNU libc extension. Do not do any padding
when performing numerical outputs.
$_* - GNU libc extension. Explicitly specify space for padding.
%0* - GNU libc extension. Explicitly specify zero
for padding.
%% - is replaced by %.
PGTYPEStimestamp_sub
Subtract one timestamp from another one and save the result in a
variable of type interval.
int PGTYPEStimestamp_sub(timestamp *ts1, timestamp *ts2, interval *iv);
The function will subtract the timestamp variable that ts2>
points to from the timestamp variable that ts1> points to
and will store the result in the interval variable that iv>
points to.
Upon success, the function returns 0 and a negative value if an
error occurred.
PGTYPEStimestamp_defmt_asc
Parse a timestamp value from its textual representation using a
formatting mask.
int PGTYPEStimestamp_defmt_asc(char *str, char *fmt, timestamp *d);
The function receives the textual representation of a timestamp in the
variable str> as well as the formatting mask to use in the
variable fmt>. The result will be stored in the variable
that d> points to.
If the formatting mask fmt> is NULL, the function will fall
back to the default formatting mask which is %Y-%m-%d
%H:%M:%S.
This is the reverse function to . See the documentation there in
order to find out about the possible formatting mask entries.
PGTYPEStimestamp_add_interval
Add an interval variable to a timestamp variable.
int PGTYPEStimestamp_add_interval(timestamp *tin, interval *span, timestamp *tout);
The function receives a pointer to a timestamp variable tin>
and a pointer to an interval variable span>. It adds the
interval to the timestamp and saves the resulting timestamp in the
variable that tout> points to.
Upon success, the function returns 0 and a negative value if an
error occurred.
PGTYPEStimestamp_sub_interval
Subtract an interval variable from a timestamp variable.
int PGTYPEStimestamp_sub_interval(timestamp *tin, interval *span, timestamp *tout);
The function subtracts the interval variable that span>
points to from the timestamp variable that tin> points to
and saves the result into the variable that tout> points
to.
Upon success, the function returns 0 and a negative value if an
error occurred.
The interval type
The interval type in C enables your programs to deal with data of the SQL
type interval. See for the equivalent
type in the PostgreSQL> server.
The following functions can be used to work with the interval type:
PGTYPESinterval_new
Return a pointer to a newly allocated interval variable.
interval *PGTYPESinterval_new(void);
PGTYPESinterval_free
Release the memory of a previously allocated interval variable.
void PGTYPESinterval_new(interval *intvl);
PGTYPESinterval_from_asc
Parse an interval from its textual representation.
interval *PGTYPESinterval_from_asc(char *str, char **endptr);
The function parses the input string str> and returns a
pointer to an allocated interval variable.
At the moment ECPG always parses
the complete string and so it currently does not support to store the
address of the first invalid character in *endptr.
You can safely set endptr to NULL.
PGTYPESinterval_to_asc
Convert a variable of type interval to its textual representation.
char *PGTYPESinterval_to_asc(interval *span);
The function converts the interval variable that span>
points to into a C char*. The output looks like this example:
@ 1 day 12 hours 59 mins 10 secs.
PGTYPESinterval_copy
Copy a variable of type interval.
int PGTYPESinterval_copy(interval *intvlsrc, interval *intvldest);
The function copies the interval variable that intvlsrc>
points to into the variable that intvldest> points to. Note
that you need to allocate the memory for the destination variable
before.
The decimal type
The decimal type is similar to the numeric type. However it is limited to
a maximum precision of 30 significant digits. In contrast to the numeric
type which can be created on the heap only, the decimal type can be
created either on the stack or on the heap (by means of the functions
PGTYPESdecimal_new> and
PGTYPESdecimal_free>).
There are a lot of other functions that deal with the decimal type in the
Informix compatibility mode described in .
The following functions can be used to work with the decimal type and are
not only contained in the libcompat> library.
PGTYPESdecimal_new
Request a pointer to a newly allocated decimal variable.
decimal *PGTYPESdecimal_new(void);
PGTYPESdecimal_free
Free a decimal type, release all of its memory.
void PGTYPESdecimal_free(decimal *var);
errno values of pgtypeslibPGTYPES_NUM_BAD_NUMERIC
An argument should contain a numeric variable (or point to a numeric
variable) but in fact its in-memory representation was invalid.
PGTYPES_NUM_OVERFLOW
An overflow occurred. Since the numeric type can deal with almost
arbitrary precision, converting a numeric variable into other types
might cause overflow.
PGTYPES_NUM_UNDERFLOW
An underflow occurred. Since the numeric type can deal with almost
arbitrary precision, converting a numeric variable into other types
might cause underflow.
PGTYPES_NUM_DIVIDE_ZERO
A division by zero has been attempted.
PGTYPES_DATE_BAD_DATEPGTYPES_DATE_ERR_EARGSPGTYPES_DATE_ERR_ENOSHORTDATEPGTYPES_INTVL_BAD_INTERVALPGTYPES_DATE_ERR_ENOTDMYPGTYPES_DATE_BAD_DAYPGTYPES_DATE_BAD_MONTHPGTYPES_TS_BAD_TIMESTAMPSpecial constants of pgtypeslibPGTYPESInvalidTimestamp
A value of type timestamp representing an invalid time stamp. This is
returned by the function PGTYPEStimestamp_from_asc> on
parse error.
Note that due to the internal representation of the timestamp data type,
PGTYPESInvalidTimestamp is also a valid timestamp at
the same time. It is set to 1899-12-31 23:59:59>. In order
to detect errors, make sure that your application does not only test
for PGTYPESInvalidTimestamp but also for
errno != 0> after each call to
PGTYPEStimestamp_from_asc>.
Using Descriptor Areas
An SQL descriptor area is a more sophisticated method for processing
the result of a SELECT, FETCH or
a DESCRIBE statement. An SQL descriptor area groups
the data of one row of data together with metadata items into one
data structure. The metadata is particularly useful when executing
dynamic SQL statements, where the nature of the result columns might
not be known ahead of time. PostgreSQL provides two ways to use
Descriptor Areas: the named SQL Descriptor Areas and the C-structure
SQLDAs.
Named SQL Descriptor Areas
A named SQL descriptor area consists of a header, which contains
information concerning the entire descriptor, and one or more item
descriptor areas, which basically each describe one column in the
result row.
Before you can use an SQL descriptor area, you need to allocate one:
EXEC SQL ALLOCATE DESCRIPTOR identifier;
The identifier serves as the variable name of the
descriptor area. The scope of the allocated descriptor is WHAT?.
When you don't need the descriptor anymore, you should deallocate
it:
EXEC SQL DEALLOCATE DESCRIPTOR identifier;
To use a descriptor area, specify it as the storage target in an
INTO clause, instead of listing host variables:
EXEC SQL FETCH NEXT FROM mycursor INTO SQL DESCRIPTOR mydesc;
If the result set is empty, the Descriptor Area will still contain
the metadata from the query, i.e. the field names.
For not yet executed prepared queries, the DESCRIBE
statement can be used to get the metadata of the result set:
EXEC SQL BEGIN DECLARE SECTION;
char *sql_stmt = "SELECT * FROM table1";
EXEC SQL END DECLARE SECTION;
EXEC SQL PREPARE stmt1 FROM :sql_stmt;
EXEC SQL DESCRIBE stmt1 INTO SQL DESCRIPTOR mydesc;
Before PostgreSQL 9.0, the SQL keyword was optional,
so using DESCRIPTOR and SQL DESCRIPTOR
produced named SQL Descriptor Areas. Now it is mandatory, omitting
the SQL keyword produces SQLDA Descriptor Areas,
see .
In DESCRIBE and FETCH statements,
the INTO and USING keywords can be
used to similarly: they produce the result set and the metadata in a
Descriptor Area.
Now how do you get the data out of the descriptor area? You can
think of the descriptor area as a structure with named fields. To
retrieve the value of a field from the header and store it into a
host variable, use the following command:
EXEC SQL GET DESCRIPTOR name :hostvar = field;
Currently, there is only one header field defined:
COUNT, which tells how many item
descriptor areas exist (that is, how many columns are contained in
the result). The host variable needs to be of an integer type. To
get a field from the item descriptor area, use the following
command:
EXEC SQL GET DESCRIPTOR name VALUE num :hostvar = field;
num can be a literal integer or a host
variable containing an integer. Possible fields are:
CARDINALITY (integer)
number of rows in the result set
DATA
actual data item (therefore, the data type of this field
depends on the query)
DATETIME_INTERVAL_CODE (integer)
?
DATETIME_INTERVAL_PRECISION (integer)
not implemented
INDICATOR (integer)
the indicator (indicating a null value or a value truncation)
KEY_MEMBER (integer)
not implemented
LENGTH (integer)
length of the datum in characters
NAME (string)
name of the column
NULLABLE (integer)
not implemented
OCTET_LENGTH (integer)
length of the character representation of the datum in bytes
PRECISION (integer)
precision (for type numeric)
RETURNED_LENGTH (integer)
length of the datum in characters
RETURNED_OCTET_LENGTH (integer)
length of the character representation of the datum in bytes
SCALE (integer)
scale (for type numeric)
TYPE (integer)
numeric code of the data type of the column
In EXECUTE, DECLARE and OPEN
statements, the effect of the INTO and USING
keywords are different. A Descriptor Area can also be manually built to
provide the input parameters for a query or a cursor and
USING SQL DESCRIPTOR name
is the way to pass the input parameters into a parametrized query. The statement
to build a named SQL Descriptor Area is below:
EXEC SQL SET DESCRIPTOR name VALUE numfield = :hostvar;
PostgreSQL supports retrieving more that one record in one FETCH
statement and storing the data in host variables in this case assumes that the
variable is an array. E.g.:
EXEC SQL BEGIN DECLARE SECTION;
int id[5];
EXEC SQL END DECLARE SECTION;
EXEC SQL FETCH 5 FROM mycursor INTO SQL DESCRIPTOR mydesc;
EXEC SQL GET DESCRIPTOR mydesc VALUE 1 :id = DATA;
SQLDA Descriptor Areas
An SQLDA Descriptor Area is a C language structure which can be also used
to get the result set and the metadata of a query. One structure stores one
record from the result set.
EXEC SQL include sqlda.h;
sqlda_t *mysqlda;
EXEC SQL FETCH 3 FROM mycursor INTO DESCRIPTOR mysqlda;
Note that the SQL keyword is omitted. The paragraphs about
the use cases of the INTO and USING
keywords in also apply here with an addition.
In a DESCRIBE statement the DESCRIPTOR
keyword can be completely omitted if the INTO keyword is used:
EXEC SQL DESCRIBE prepared_statement INTO mysqlda;
The structure of SQLDA 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];
};
typedef struct sqlvar_struct sqlvar_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:
sqldaid>
It contains the "SQLDA " literal string.
sqldabc>
It contains the size of the allocated space in bytes.
sqln>
It contains the number of input parameters for a parametrized query
case it's passed into OPEN, DECLARE or
EXECUTE statements using the USING
keyword. In case it's used as output of SELECT,
EXECUTE or FETCH statements,
its value is the same as sqld
statement
sqld>
It contains the number of fields in a result set.
desc_next>
If the query returns more than one records, multiple linked SQLDA structures
are returned, the first record is stored in the SQLDA returned in the
sqlvar>
This is the array of the fields in the result set. The fields are:
sqltype>
It contains the type identifier of the field. For values,
see enum ECPGttype in ecpgtype.h.
sqllen>
It contains the binary length of the field. E.g. 4 bytes for ECPGt_int.
sqldata>(char *)sqldata points to the data.
sqlind>(char *)sqlind points to the NULL indicator for data.
0 means NOT NULL, -1 means NULL.
sqlname>struct sqlname sqlname contains the name of the field
in a structure:
struct sqlname
{
short length;
char data[NAMEDATALEN];
};
length>sqlname.length contains the length of the field name.
data>sqlname.data contains the actual field name.
Informix compatibility modeecpg 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
precompiler for Informix E/SQL. Generally spoken this will allow you to use
the dollar sign instead of the EXEC SQL> primitive to introduce
embedded SQL commands.:
$int j = 3;
$CONNECT TO :dbname;
$CREATE TABLE test(i INT PRIMARY KEY, j INT);
$INSERT INTO test(i, j) VALUES (7, :j);
$COMMIT;
There are two compatibility modes: INFORMIX>, INFORMIX_SE>
When linking programs that use this compatibility mode, remember to link
against libcompat> that is shipped with ECPG.
Besides the previously explained syntactic sugar, the Informix compatibility
mode ports some functions for input, output and transformation of data as
well as embedded SQL statements known from E/SQL to ECPG.
Informix compatibility mode is closely connected to the pgtypeslib library
of ECPG. pgtypeslib maps SQL data types to data types within the C host
program and most of the additional functions of the Informix compatibility
mode allow you to operate on those C host program types. Note however that
the extent of the compatibility is limited. It does not try to copy Informix
behavior; it allows you to do more or less the same operations and gives
you functions that have the same name and the same basic behavior but it is
no drop-in replacement if you are using Informix at the moment. Moreover,
some of the data types are different. For example,
PostgreSQL's datetime and interval types do not
know about ranges like for example YEAR TO MINUTE> so you won't
find support in ECPG for that either.
Additional types
The Informix-special "string" pseudo-type for storing right-trimmed character string data is now
supported in Informix-mode without using typedef. In fact, in Informix-mode,
ECPG refuses to process source files that contain typedef sometype string;
EXEC SQL BEGIN DECLARE SECTION;
string userid; /* this variable will contain trimmed data */
EXEC SQL END DECLARE SECTION;
EXEC SQL FETCH MYCUR INTO :userid;
Additional/missing embedded SQL statementsCLOSE DATABASE>
This statement closes the current connection. In fact, this is a
synonym for ECPG's DISCONNECT CURRENT>.:
$CLOSE DATABASE; /* close the current connection */
EXEC SQL CLOSE DATABASE;
FREE cursor_name>
Due to the differences how ECPG works compared to Informix's ESQL/C (i.e. which steps
are purely grammar transformations and which steps rely on the underlying run-time library)
there is no FREE cursor_name> statement in ECPG. This is because in ECPG,
DECLARE CURSOR doesn't translate to a function call into
the run-time library that uses to the cursor name. This means that there's no run-time
bookkeeping of SQL cursors in the ECPG run-time library, only in the PostgreSQL server.
FREE statement_name>FREE statement_name> is a synonym for DEALLOCATE PREPARE statement_name>.
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;
};
struct sqlda_compat
{
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;
typedef struct sqlda_compat sqlda_t;
The global properties are:
sqld>
The number of fields in the SQLDA> descriptor.
sqlvar>
Pointer to the per-field properties.
desc_name>
Unused, filled with zero-bytes.
desc_occ>
Size of the allocated structure.
desc_next>
Pointer to the next SQLDA structure if the result set contains more than one records.
reserved>
Unused pointer, contains NULL. Kept for Informix-compatibility.
The per-field properties are below, they are stored in the sqlvar array:
sqltype>
Type of the field. Constants are in sqltypes.hsqllen>
Length of the field data.
sqldata>
Pointer to the field data. The pointer is of char * type,
the data pointed by it is in a binary format. Example:
int intval;
switch (sqldata->sqlvar[i].sqltype)
{
case SQLINTEGER:
intval = *(int *)sqldata->sqlvar[i].sqldata;
break;
...
}
sqlind>
Pointer to the NULL indicator. If returned by DESCRIBE or FETCH then it's always a valid pointer.
If used as input for EXECUTE ... USING sqlda; then NULL-pointer value means
that the value for this field is non-NULL. Otherwise a valid pointer and sqlitype
has to be properly set. Example:
if (*(int2 *)sqldata->sqlvar[i].sqlind != 0)
printf("value is NULL\n");
sqlname>
Name of the field. 0-terminated string.
sqlformat>
Reserved in Informix, value of PQfformat()> for the field.
sqlitype>
Type of the NULL indicator data. It's always SQLSMINT when returning data from the server.
When the SQLDA is used for a parametrized query, the data is treated
according to the set type.
sqlilen>
Length of the NULL indicator data.
sqlxid>
Extended type of the field, result of PQftype()>.
sqltypename>sqltypelen>sqlownerlen>sqlsourcetype>sqlownername>sqlsourceid>sqlflags>sqlreserved>
Unused.
sqlilongdata>
It equals to sqldata if sqllen is larger than 32KB.
Example:
EXEC SQL INCLUDE sqlda.h;
sqlda_t *sqlda; /* This doesn't need to be under embedded DECLARE SECTION */
EXEC SQL BEGIN DECLARE SECTION;
char *prep_stmt = "select * from table1";
int i;
EXEC SQL END DECLARE SECTION;
...
EXEC SQL PREPARE mystmt FROM :prep_stmt;
EXEC SQL DESCRIBE mystmt INTO sqlda;
printf("# of fields: %d\n", sqlda->sqld);
for (i = 0; i < sqlda->sqld; i++)
printf("field %d: \"%s\"\n", sqlda->sqlvar[i]->sqlname);
EXEC SQL DECLARE mycursor CURSOR FOR mystmt;
EXEC SQL OPEN mycursor;
EXEC SQL WHENEVER NOT FOUND GOTO out;
while (1)
{
EXEC SQL FETCH mycursor USING sqlda;
}
EXEC SQL CLOSE mycursor;
free(sqlda); /* The main structure is all to be free(),
* sqlda and sqlda->sqlvar is in one allocated area */
For more information, see the sqlda.h> header and the
src/interfaces/ecpg/test/compat_informix/sqlda.pgc regression test.
Additional functionsdecadd>
Add two decimal type values.
int decadd(decimal *arg1, decimal *arg2, decimal *sum);
The function receives a pointer to the first operand of type decimal
(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_UNDERFLOW> in case of underflow. -1 is returned for
other failures and errno> is set to the respective errno> number of the
pgtypeslib.
deccmp>
Compare two variables of type decimal.
int deccmp(decimal *arg1, decimal *arg2);
The function receives a pointer to the first decimal value
(arg1>), a pointer to the second decimal value
(arg2>) and returns an integer value that indicates which is
the bigger value.
1, if the value that arg1> points to is bigger than the
value that var2> points to
-1, if the value that arg1> points to is smaller than the
value that arg2> points to
0, if the value that arg1> points to and the value that
arg2> points to are equal
deccopy>
Copy a decimal value.
void deccopy(decimal *src, decimal *target);
The function receives a pointer to the decimal value that should be
copied as the first argument (src>) and a pointer to the
target structure of type decimal (target>) as the second
argument.
deccvasc>
Convert a value from its ASCII representation into a decimal type.
int deccvasc(char *cp, int len, decimal *np);
The function receives a pointer to string that contains the string
representation of the number to be converted (cp>) as well
as its length len>. np> is a pointer to the
decimal value that saves the result of the operation.
Valid formats are for example:
-2,
.794,
+3.44,
592.49E07 or
-32.84e-4.
The function returns 0 on success. If overflow or underflow occurred,
ECPG_INFORMIX_NUM_OVERFLOW> or
ECPG_INFORMIX_NUM_UNDERFLOW> is returned. If the ASCII
representation could not be parsed,
ECPG_INFORMIX_BAD_NUMERIC> is returned or
ECPG_INFORMIX_BAD_EXPONENT> if this problem occurred while
parsing the exponent.
deccvdbl>
Convert a value of type double to a value of type decimal.
int deccvdbl(double dbl, decimal *np);
The function receives the variable of type double that should be
converted as its first argument (dbl>). As the second
argument (np>), the function receives a pointer to the
decimal variable that should hold the result of the operation.
The function returns 0 on success and a negative value if the
conversion failed.
deccvint>
Convert a value of type int to a value of type decimal.
int deccvint(int in, decimal *np);
The function receives the variable of type int that should be
converted as its first argument (in>). As the second
argument (np>), the function receives a pointer to the
decimal variable that should hold the result of the operation.
The function returns 0 on success and a negative value if the
conversion failed.
deccvlong>
Convert a value of type long to a value of type decimal.
int deccvlong(long lng, decimal *np);
The function receives the variable of type long that should be
converted as its first argument (lng>). As the second
argument (np>), the function receives a pointer to the
decimal variable that should hold the result of the operation.
The function returns 0 on success and a negative value if the
conversion failed.
decdiv>
Divide two variables of type decimal.
int decdiv(decimal *n1, decimal *n2, decimal *result);
The function receives pointers to the variables that are the first
(n1>) and the second (n2>) operands and
calculates n1>/n2>. result> is a
pointer to the variable that should hold the result of the operation.
On success, 0 is returned and a negative value if the division fails.
If overflow or underflow occurred, the function returns
ECPG_INFORMIX_NUM_OVERFLOW> or
ECPG_INFORMIX_NUM_UNDERFLOW> respectively. If an attempt to
divide by zero is observed, the function returns
ECPG_INFORMIX_DIVIDE_ZERO.
decmul>
Multiply two decimal values.
int decmul(decimal *n1, decimal *n2, decimal *result);
The function receives pointers to the variables that are the first
(n1>) and the second (n2>) operands and
calculates n1>*n2>. result> is a
pointer to the variable that should hold the result of the operation.
On success, 0 is returned and a negative value if the multiplication
fails. If overflow or underflow occurred, the function returns
ECPG_INFORMIX_NUM_OVERFLOW> or
ECPG_INFORMIX_NUM_UNDERFLOW> respectively.
decsub>
Subtract one decimal value from another.
int decsub(decimal *n1, decimal *n2, decimal *result);
The function receives pointers to the variables that are the first
(n1>) and the second (n2>) operands and
calculates n1>-n2>. result> is a
pointer to the variable that should hold the result of the operation.
On success, 0 is returned and a negative value if the subtraction
fails. If overflow or underflow occurred, the function returns
ECPG_INFORMIX_NUM_OVERFLOW> or
ECPG_INFORMIX_NUM_UNDERFLOW> respectively.
dectoasc>
Convert a variable of type decimal to its ASCII representation in a C
char* string.
int dectoasc(decimal *np, char *cp, int len, int right)
The function receives a pointer to a variable of type decimal
(np>) that it converts to its textual representation.
cp> is the buffer that should hold the result of the
operation. The parameter right> specifies, how many digits
right of the decimal point should be included in the output. The result
will be rounded to this number of decimal digits. Setting
right> to -1 indicates that all available decimal digits
should be included in the output. If the length of the output buffer,
which is indicated by len> is not sufficient to hold the
textual representation including the trailing NUL character, only a
single *> character is stored in the result and -1 is
returned.
The function returns either -1 if the buffer cp> was too
small or ECPG_INFORMIX_OUT_OF_MEMORY> if memory was
exhausted.
dectodbl>
Convert a variable of type decimal to a double.
int dectodbl(decimal *np, double *dblp);
The function receives a pointer to the decimal value to convert
(np>) and a pointer to the double variable that
should hold the result of the operation (dblp>).
On success, 0 is returned and a negative value if the conversion
failed.
dectoint>
Convert a variable to type decimal to an integer.
int dectoint(decimal *np, int *ip);
The function receives a pointer to the decimal value to convert
(np>) and a pointer to the integer variable that
should hold the result of the operation (ip>).
On success, 0 is returned and a negative value if the conversion
failed. If an overflow occurred, ECPG_INFORMIX_NUM_OVERFLOW>
is returned.
Note that the ECPG implementation differs from the Informix
implementation. Informix limits an integer to the range from -32767 to
32767, while the limits in the ECPG implementation depend on the
architecture (-INT_MAX .. INT_MAX>).
dectolong>
Convert a variable to type decimal to a long integer.
int dectolong(decimal *np, long *lngp);
The function receives a pointer to the decimal value to convert
(np>) and a pointer to the long variable that
should hold the result of the operation (lngp>).
On success, 0 is returned and a negative value if the conversion
failed. If an overflow occurred, ECPG_INFORMIX_NUM_OVERFLOW>
is returned.
Note that the ECPG implementation differs from the Informix
implementation. Informix limits a long integer to the range from
-2,147,483,647 to 2,147,483,647, while the limits in the ECPG
implementation depend on the architecture (-LONG_MAX ..
LONG_MAX>).
rdatestr>
Converts a date to a C char* string.
int rdatestr(date d, char *str);
The function receives two arguments, the first one is the date to
convert (d> and the second one is a pointer to the target
string. The output format is always yyyy-mm-dd>, so you need
to allocate at least 11 bytes (including the NUL-terminator) for the
string.
The function returns 0 on success and a negative value in case of
error.
Note that ECPG's implementation differs from the Informix
implementation. In Informix the format can be influenced by setting
environment variables. In ECPG however, you cannot change the output
format.
rstrdate>
Parse the textual representation of a date.
int rstrdate(char *str, date *d);
The function receives the textual representation of the date to convert
(str>) and a pointer to a variable of type date
(d>). This function does not allow you to specify a format
mask. It uses the default format mask of Informix which is
mm/dd/yyyy>. Internally, this function is implemented by
means of rdefmtdate>. Therefore, rstrdate> is
not faster and if you have the choice you should opt for
rdefmtdate> which allows you to specify the format mask
explicitly.
The function returns the same values as rdefmtdate>.
rtoday>
Get the current date.
void rtoday(date *d);
The function receives a pointer to a date variable (d>)
that it sets to the current date.
Internally this function uses the
function.
rjulmdy>
Extract the values for the day, the month and the year from a variable
of type date.
int rjulmdy(date d, short mdy[3]);
The function receives the date d> and a pointer to an array
of 3 short integer values mdy>. The variable name indicates
the sequential order: mdy[0]> will be set to contain the
number of the month, mdy[1]> will be set to the value of the
day and mdy[2]> will contain the year.
The function always returns 0 at the moment.
Internally the function uses the
function.
rdefmtdate>
Use a format mask to convert a character string to a value of type
date.
int rdefmtdate(date *d, char *fmt, char *str);
The function receives a pointer to the date value that should hold the
result of the operation (d>), the format mask to use for
parsing the date (fmt>) and the C char* string containing
the textual representation of the date (str>). The textual
representation is expected to match the format mask. However you do not
need to have a 1:1 mapping of the string to the format mask. The
function only analyzes the sequential order and looks for the literals
yy or yyyy that indicate the
position of the year, mm to indicate the position of
the month and dd to indicate the position of the
day.
The function returns the following values:
0 - The function terminated successfully.
ECPG_INFORMIX_ENOSHORTDATE> - The date does not contain
delimiters between day, month and year. In this case the input
string must be exactly 6 or 8 bytes long but isn't.
ECPG_INFORMIX_ENOTDMY> - The format string did not
correctly indicate the sequential order of year, month and day.
ECPG_INFORMIX_BAD_DAY> - The input string does not
contain a valid day.
ECPG_INFORMIX_BAD_MONTH> - The input string does not
contain a valid month.
ECPG_INFORMIX_BAD_YEAR> - The input string does not
contain a valid year.
Internally this function is implemented to use the function. See the reference there for a
table of example input.
rfmtdate>
Convert a variable of type date to its textual representation using a
format mask.
int rfmtdate(date d, char *fmt, char *str);
The function receives the date to convert (d>), the format
mask (fmt>) and the string that will hold the textual
representation of the date (str>).
On success, 0 is returned and a negative value if an error occurred.
Internally this function uses the
function, see the reference there for examples.
rmdyjul>
Create a date value from an array of 3 short integers that specify the
day, the month and the year of the date.
int rmdyjul(short mdy[3], date *d);
The function receives the array of the 3 short integers
(mdy>) and a pointer to a variable of type date that should
hold the result of the operation.
Currently the function returns always 0.
Internally the function is implemented to use the function .
rdayofweek>
Return a number representing the day of the week for a date value.
int rdayofweek(date d);
The function receives the date variable d> as its only
argument and returns an integer that indicates the day of the week for
this date.
0 - Sunday
1 - Monday
2 - Tuesday
3 - Wednesday
4 - Thursday
5 - Friday
6 - Saturday
Internally the function is implemented to use the function .
dtcurrent>
Retrieve the current timestamp.
void dtcurrent(timestamp *ts);
The function retrieves the current timestamp and saves it into the
timestamp variable that ts> points to.
dtcvasc>
Parses a timestamp from its textual representation
into a timestamp variable.
int dtcvasc(char *str, timestamp *ts);
The function receives the string to parse (str>) and a
pointer to the timestamp variable that should hold the result of the
operation (ts>).
The function returns 0 on success and a negative value in case of
error.
Internally this function uses the function. See the reference there
for a table with example inputs.
dtcvfmtasc>
Parses a timestamp from its textual representation
using a format mask into a timestamp variable.
dtcvfmtasc(char *inbuf, char *fmtstr, timestamp *dtvalue)
The function receives the string to parse (inbuf>), the
format mask to use (fmtstr>) and a pointer to the timestamp
variable that should hold the result of the operation
(dtvalue>).
This function is implemented by means of the function. See the documentation
there for a list of format specifiers that can be used.
The function returns 0 on success and a negative value in case of
error.
dtsub>
Subtract one timestamp from another and return a variable of type
interval.
int dtsub(timestamp *ts1, timestamp *ts2, interval *iv);
The function will subtract the timestamp variable that ts2>
points to from the timestamp variable that ts1> points to
and will store the result in the interval variable that iv>
points to.
Upon success, the function returns 0 and a negative value if an
error occurred.
dttoasc>
Convert a timestamp variable to a C char* string.
int dttoasc(timestamp *ts, char *output);
The function receives a pointer to the timestamp variable to convert
(ts>) and the string that should hold the result of the
operation output>). It converts ts> to its
textual representation according to the SQL standard, which is
be YYYY-MM-DD HH:MM:SS.
Upon success, the function returns 0 and a negative value if an
error occurred.
dttofmtasc>
Convert a timestamp variable to a C char* using a format mask.
int dttofmtasc(timestamp *ts, char *output, int str_len, char *fmtstr);
The function receives a pointer to the timestamp to convert as its
first argument (ts>), a pointer to the output buffer
(output>), the maximal length that has been allocated for
the output buffer (str_len) and the format mask to
use for the conversion (fmtstr).
Upon success, the function returns 0 and a negative value if an
error occurred.
Internally, this function uses the function. See the reference there for
information on what format mask specifiers can be used.
intoasc>
Convert an interval variable to a C char* string.
int intoasc(interval *i, char *str);
The function receives a pointer to the interval variable to convert
(i>) and the string that should hold the result of the
operation str>). It converts i> to its
textual representation according to the SQL standard, which is
be YYYY-MM-DD HH:MM:SS.
Upon success, the function returns 0 and a negative value if an
error occurred.
rfmtlong>
Convert a long integer value to its textual representation using a
format mask.
int rfmtlong(long lng_val, char *fmt, char *outbuf);
The function receives the long value lng_val>, the format
mask fmt> and a pointer to the output buffer
outbuf>. It converts the long value according to the format
mask to its textual representation.
The format mask can be composed of the following format specifying
characters:
* (asterisk) - if this position would be blank
otherwise, fill it with an asterisk.
& (ampersand) - if this position would be
blank otherwise, fill it with a zero.
# - turn leading zeroes into blanks.
< - left-justify the number in the string.
, (comma) - group numbers of four or more digits
into groups of three digits separated by a comma.
. (period) - this character separates the
whole-number part of the number from the fractional part.
- (minus) - the minus sign appears if the number
is a negative value.
+ (plus) - the plus sign appears if the number is
a positive value.
( - this replaces the minus sign in front of the
negative number. The minus sign will not appear.
) - this character replaces the minus and is
printed behind the negative value.
$ - the currency symbol.
rupshift>
Convert a string to upper case.
void rupshift(char *str);
The function receives a pointer to the string and transforms every
lower case character to upper case.
byleng>
Return the number of characters in a string without counting trailing
blanks.
int byleng(char *str, int len);
The function expects a fixed-length string as its first argument
(str>) and its length as its second argument
(len>). It returns the number of significant characters,
that is the length of the string without trailing blanks.
ldchar>
Copy a fixed-length string into a null-terminated string.
void ldchar(char *src, int len, char *dest);
The function receives the fixed-length string to copy
(src>), its length (len>) and a pointer to the
destination memory (dest>). Note that you need to reserve at
least len+1> bytes for the string that dest>
points to. The function copies at most len> bytes to the new
location (less if the source string has trailing blanks) and adds the
null-terminator.
rgetmsg>
int rgetmsg(int msgnum, char *s, int maxsize);
This function exists but is not implemented at the moment!
rtypalign>
int rtypalign(int offset, int type);
This function exists but is not implemented at the moment!
rtypmsize>
int rtypmsize(int type, int len);
This function exists but is not implemented at the moment!
rtypwidth>
int rtypwidth(int sqltype, int sqllen);
This function exists but is not implemented at the moment!
rsetnull>
Set a variable to NULL.
int rsetnull(int t, char *ptr);
The function receives an integer that indicates the type of the
variable and a pointer to the variable itself that is casted to a C
char* pointer.
The following types exist:
CCHARTYPE - For a variable of type char or char*CSHORTTYPE - For a variable of type short intCINTTYPE - For a variable of type intCBOOLTYPE - For a variable of type booleanCFLOATTYPE - For a variable of type floatCLONGTYPE - For a variable of type longCDOUBLETYPE - For a variable of type doubleCDECIMALTYPE - For a variable of type decimalCDATETYPE - For a variable of type dateCDTIMETYPE - For a variable of type timestamp
Here is an example of a call to this function:
risnull>
Test if a variable is NULL.
int risnull(int t, char *ptr);
The function receives the type of the variable to test (t>)
as well a pointer to this variable (ptr>). Note that the
latter needs to be casted to a char*. See the function for a list of possible variable types.
Here is an example of how to use this function:
Additional constants
Note that all constants here describe errors and all of them are defined
to represent negative values. In the descriptions of the different
constants you can also find the value that the constants represent in the
current implementation. However you should not rely on this number. You can
however rely on the fact all of them are defined to represent negative
values.
ECPG_INFORMIX_NUM_OVERFLOW>
Functions return this value if an overflow occurred in a
calculation. Internally it is defined to -1200 (the Informix
definition).
ECPG_INFORMIX_NUM_UNDERFLOW>
Functions return this value if an underflow occurred in a calculation.
Internally it is defined to -1201 (the Informix definition).
ECPG_INFORMIX_DIVIDE_ZERO>
Functions return this value if an attempt to divide by zero is
observed. Internally it is defined to -1202 (the Informix definition).
ECPG_INFORMIX_BAD_YEAR>
Functions return this value if a bad value for a year was found while
parsing a date. Internally it is defined to -1204 (the Informix
definition).
ECPG_INFORMIX_BAD_MONTH>
Functions return this value if a bad value for a month was found while
parsing a date. Internally it is defined to -1205 (the Informix
definition).
ECPG_INFORMIX_BAD_DAY>
Functions return this value if a bad value for a day was found while
parsing a date. Internally it is defined to -1206 (the Informix
definition).
ECPG_INFORMIX_ENOSHORTDATE>
Functions return this value if a parsing routine needs a short date
representation but did not get the date string in the right length.
Internally it is defined to -1209 (the Informix definition).
ECPG_INFORMIX_DATE_CONVERT>
Functions return this value if Internally it is defined to -1210 (the
Informix definition).
ECPG_INFORMIX_OUT_OF_MEMORY>
Functions return this value if Internally it is defined to -1211 (the
Informix definition).
ECPG_INFORMIX_ENOTDMY>
Functions return this value if a parsing routine was supposed to get a
format mask (like mmddyy>) but not all fields were listed
correctly. Internally it is defined to -1212 (the Informix definition).
ECPG_INFORMIX_BAD_NUMERIC>
Functions return this value either if a parsing routine cannot parse
the textual representation for a numeric value because it contains
errors or if a routine cannot complete a calculation involving numeric
variables because at least one of the numeric variables is invalid.
Internally it is defined to -1213 (the Informix definition).
ECPG_INFORMIX_BAD_EXPONENT>
Functions return this value if Internally it is defined to -1216 (the
Informix definition).
ECPG_INFORMIX_BAD_DATE>
Functions return this value if Internally it is defined to -1218 (the
Informix definition).
ECPG_INFORMIX_EXTRA_CHARS>
Functions return this value if Internally it is defined to -1264 (the
Informix definition).
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 conditionaction;
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 labelGO 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.
SQLSTATE vs SQLCODE
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:
-12 (ECPG_OUT_OF_MEMORY)
Indicates that your virtual memory is exhausted. (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)
-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)
-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)
-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)
-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)
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)
Preprocessor directivesIncluding 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
This section explains how ECPG works
internally. This information can occasionally be useful to help
users understand how to use ECPG.
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 command starts with EXEC
SQL and ends 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
EXEC SQL DECLARE> section.
The most important function in the library is
ECPGdo, which takes care of executing most
commands. It takes a variable number of arguments. This can easily
add up to 50 or so arguments, and we hope this will not be a
problem on any platform.
The arguments are:
A line number
This is the line number of the original line; used in error
messages only.
A string
This is the SQL command 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
command. Where the variables should go the string contains
?.
Input variables
Every input variable causes ten arguments to be created. (See below.)
ECPGt_EOIT>
An enum> telling that there are no more input
variables.
Output variables
Every output variable causes ten arguments to be created.
(See below.) These variables are filled by the function.
ECPGt_EORT>
An enum> telling that there are no more variables.
For every variable that is part of the SQL
command, the function gets ten 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 indicator variable.
0
The number of elements in the indicator array (for array fetches).
The offset to the next element in the indicator array (for
array fetches).
Note that not all SQL commands are treated in this way. For
instance, an open cursor statement like:
EXEC SQL OPEN cursor;
is not copied to the output. Instead, the cursor's
DECLARE> command is used at the position of the OPEN> command
because it indeed opens the cursor.
Here is a complete example describing the output of the
preprocessor of a file foo.pgc (details might
change with each particular version of the preprocessor):
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:
;
#include ;
/* 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 here is added for readability and not
something the preprocessor does.)