Linux Tolke Michael Meskes 1996-1997 Linus Tolke 1998 Michael Meskes Transcribed 1998-02-12 <Application>ecpg</Application> - Embedded <Acronym>SQL</Acronym> in <Acronym>C</Acronym> This describes an embedded SQL in C package for Postgres. It is written by Linus Tolke and Michael Meskes. Permission is granted to copy and use in the same way as you are allowed to copy and use the rest of the PostgreSQL. Why Embedded <Acronym>SQL</Acronym>? Embedded SQL has some small advantages over other ways to handle SQL queries. It takes care of all the tedious moving of information to and from variables in your C program. Many RDBMS packages support this embedded language. There is an ANSI-standard describing how the embedded language should work. Most embedded SQL preprocessors I have seen and heard of make extensions so it is difficult to obtain portability between them anyway. I have not read the standard but I hope that my implementation does not deviate too much and that it would be possible to port programs with embedded SQL written for other RDBMS packages to Postgres and thus promoting the spirit of free software. The Concept You write your program in C with some special SQL things. For declaring variables that can be used in SQL statements you need to put them in a special declare section. You use a special syntax for the SQL queries. Before compiling you run the file through the embedded SQL C preprocessor and it converts the SQL statements you used to function calls with the variables used as arguments. Both variables that are used as input to the SQL statements and variables that will contain the result are passed. Then you compile and at link time you link with a special library that contains the functions used. These functions (actually it is mostly one single function) fetches the information from the arguments, performs the SQL query using the ordinary interface (libpq) and puts back the result in the arguments dedicated for output. Then you run your program and when the control arrives to the SQL statement the SQL statement is performed against the database and you can continue with the result. How To Use <Application>egpc</Application> This section describes how to use the egpc tool. Preprocessor <Para> The preprocessor is called <Application>ecpg</Application>. After installation it resides in the <ProductName>Postgres</ProductName> <FileName>bin/</FileName> directory. <Sect2> <Title>Library <Para> The <Application>ecpg</Application> library is called <FileName>libecpg.a</FileName> or <FileName>libecpg.so</FileName>. Additionally, the library uses the <FileName>libpq</FileName> library for communication to the <ProductName>Postgres</ProductName> server so you will have to link your program with <Parameter>-lecpg -lpq</Parameter>. <Para> The library has some methods that are "hidden" but that could prove very useful sometime. <VariableList> <VarListEntry> <Term>ECPGdebug(int, FILE *stream)</Term> <ListItem> <Para> If this is called, with the first argument non-zero, then debuglogging is turned on. Debuglogging is done on <Function>stream</Function>. Most <Acronym>SQL</Acronym> statement logs its arguments and result. <Para> The most important one (<Function>ECPGdo</Function>) that is called on all <Acronym>SQL</Acronym> statements except <Command>EXEC SQL COMMIT</Command>, <Command>EXEC SQL ROLLBACK</Command>, <Command>EXEC SQL CONNECT</Command> logs both its expanded string, i.e. the string with all the input variables inserted, and the result from the <ProductName>Postgres</ProductName> server. This can be very useful when searching for errors in your <Acronym>SQL</Acronym> statements. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>ECPGstatus()</Term> <ListItem> <Para> This method returns TRUE if we are connected to a database and FALSE if not. </Para> </ListItem> </VarListEntry> </VariableList> <Sect2> <Title>Error handling <Para> To be able to detect errors from the <ProductName>Postgres</ProductName> server you include a line like <ProgramListing> exec sql include sqlca; </ProgramListing> in the include section of your file. This will define a struct and a variable with the name <Parameter>sqlca</Parameter> as following: <ProgramListing> struct sqlca { int sqlcode; struct { int sqlerrml; char sqlerrmc[1000]; } sqlerrm; } sqlca; </ProgramListing> <Para> If an error occured in the last <Acronym>SQL</Acronym> statement then <Parameter>sqlca.sqlcode</Parameter> will be non-zero. If <Parameter>sqlca.sqlcode</Parameter> is less that 0 then this is some kind of serious error, like the database definition does not match the query given. If it is bigger than 0 then this is a normal error like the table did not contain the requested row. <Para> sqlca.sqlerrm.sqlerrmc will contain a string that describes the error. The string ends with <Quote>line 23.</Quote> where the line is the line number in the source file (actually the file generated by the preprocessor but I hope I can fix this to be the line number in the input file.) <Para> List of errors that can occur: <VariableList> <VarListEntry> <Term>-1, Unsupported type %s on line %d.</Term> <ListItem> <Para> Does not normally occur. This is a sign that the preprocessor has generated something that the library does not know about. Perhaps you are running incompatible versions of the preprocessor and the library. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Too many arguments line %d.</Term> <ListItem> <Para> The preprocessor has goofed up and generated some incorrect code. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Too few arguments line %d.</Term> <ListItem> <Para> The preprocessor has goofed up and generated some incorrect code. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Error starting transaction line %d.</Term> <ListItem> <Para> <ProductName>Postgres</ProductName> signalled to us that we cannot open the connection. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Postgres error: %s line %d.</Term> <ListItem> <Para> Some <ProductName>Postgres</ProductName> error. The message contains the error message from the <ProductName>Postgres</ProductName> backend. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>1, Data not found line %d.</Term> <ListItem> <Para> This is a "normal" error that tells you that what you are quering cannot be found or we have gone through the cursor. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, To many matches line %d.</Term> <ListItem> <Para> This means that the query has returned several lines. The <Command>SELECT</Command> you made probably was not unique. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Not correctly formatted int type: %s line %d.</Term> <ListItem> <Para> This means that the host variable is of an <Type>int</Type> type and the field in the <ProductName>Postgres</ProductName> database is of another type and contains a value that cannot be interpreted as an <Type>int</Type>. The library uses <Function>strtol</Function> for this conversion. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Not correctly formatted unsigned type: %s line %d.</Term> <ListItem> <Para> This means that the host variable is of an <Type>unsigned int</Type> type and the field in the <ProductName>Postgres</ProductName> database is of another type and contains a value that cannot be interpreted as an <Type>unsigned int</Type>. The library uses <Function>strtoul</Function> for this conversion. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Not correctly formatted floating point type: %s line %d.</Term> <ListItem> <Para> This means that the host variable is of an <Type>float</Type> type and the field in the <ProductName>Postgres</ProductName> database is of another type and contains a value that cannot be interpreted as an <Type>float</Type>. The library uses <Function>strtod</Function> for this conversion. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Too few arguments line %d.</Term> <ListItem> <Para> This means that <ProductName>Postgres</ProductName> has returned more records than we have matching variables. Perhaps you have forgotten a couple of the host variables in the <Command>INTO :var1,:var2</Command>-list. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Too many arguments line %d.</Term> <ListItem> <Para> This means that <ProductName>Postgres</ProductName> has returned fewer records than we have host variables. Perhaps you have to many host variables in the <Command>INTO :var1,:var2</Command>-list. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Empty query line %d.</Term> <ListItem> <Para> <ProductName>Postgres</ProductName> returned PGRES_EMPTY_QUERY. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Error: %s line %d.</Term> <ListItem> <Para> This means that <ProductName>Postgres</ProductName> returned on of the errors PGRES_NONFATAL_ERROR, PGRES_FATAL_ERROR or PGRES_BAD_RESPONSE. Which one and why is explained in the message. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Postgres error line %d.</Term> <ListItem> <Para> <ProductName>Postgres</ProductName> returns something that the library does not know how to handle. This is probably because the version of <ProductName>Postgres</ProductName> does not match the version of the <Application>ecpg</Application> library. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Error committing line %d.</Term> <ListItem> <Para> Error during <Command>COMMIT</Command>. <Command>EXEC SQL COMMIT</Command> is translated to an <Command>end</Command> operation in <ProductName>Postgres</ProductName> and that is the operation that could not be performed. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, Error rolling back line %d.</Term> <ListItem> <Para> Error during <Command>ROLLBACK</Command>. <Command>EXEC SQL ROLLBACK</Command> is translated to an <Command>abort</Command> operation in <ProductName>Postgres</ProductName> and that is the operation that could not be performed. </Para> </ListItem> </VarListEntry> <VarListEntry> <Term>-1, ECPGconnect: could not open database %s.</Term> <ListItem> <Para> The connect to the database did not work. </Para> </ListItem> </VarListEntry> </VariableList> </Sect2> <Sect1> <Title>Limitations What will never be included and why or what cannot be done with this concept. oracles single tasking possibility Oracle version 7.0 on AIX 3 uses the OS-supported locks on the shared memory segments and allows the application designer to link an application in a so called single tasking way. Instead of starting one client process per application process both the database part and the application part is run in the same process. In later versions of oracle this is no longer supported. This would require a total redesign of the Postgres access model and that effort can not justify the performance gained. Porting From Other <Acronym>RDBMS</Acronym> Packages To be written by persons that knows the different RDBMS packages and that actually does port something... Installation Since version 0.5 ecpg is distributed together with Postgres. So you should get your precompiler, libraries and header files compiled and installed on the fly. For the Developer This section is for those that wants to develop the ecpg interface. It describes how the things work. The ambition is to make this section contain things for those that want to have a look inside and the section on How to use it should be enough for all normal questions. So, read this before looking at the internals of the ecpg. If you are not interested in how it really works, skip this section. ToDo List This version the preprocessor has some flaws: Preprocessor output The variables should be static. Preprocessor cannot do syntax checking on your SQL statements Whatever you write is copied more or less exactly to the Postgres and you will not be able to locate your errors until run-time. no restriction to strings only The PQ interface, and most of all the PQexec function, that is used by the ecpg relies on that the request is built up as a string. In some cases, like when the data contains the null character, this will be a serious problem. error codes There should be different error numbers for the different errors instead of just -1 for them all. library functions to_date et al. records Possibility to define records or structures in the declare section in a way that the record can be filled from one row in the database. This is a simpler way to handle an entire row at a time. array operations Oracle has array operations that enhances speed. When implementing it in ecpg it is done for compatibility reasons only. For them to improve speed would require a lot more insight in the Postgres internal mechanisms than I possess. indicator variables Oracle has indicator variables that tell if a value is null or if it is empty. This largely simplifies array operations and provides for a way to hack around some design flaws in the handling of VARCHAR2 (like that an empty string isn't distinguishable from a null value). I am not sure if this is an Oracle extension or part of the ANSI standard. typedefs As well as complex types like records and arrays, typedefs would be a good thing to take care of. conversion of scripts To set up a database you need a few scripts with table definitions and other configuration parameters. If you have these scripts for an old database you would like to just apply them to get a Postgres database that works in the same way. To set up a database you need a few scripts with table definitions and The functionality could be accomplished with some conversion scripts. Speed will never be accomplished in this way. To do this you need a bigger insight in the database construction and the use of the database than could be realised in a script. The Preprocessor First four lines are written to the output. Two comments and two include lines necessary for the interface to the library. Then the preprocessor works in one pass only reading the input file and writing to the output as it goes along. Normally it just echoes everything to the output without looking at it further. When it comes to an EXEC SQL statements it interviens and changes them depending on what iit is. The EXEC SQL statement can be one of these: Declare sections Declare sections begins with exec sql begin declare section; and ends with exec sql end declare section; In the section only variable declarations are allowed. Every variable declare within this section is also entered in a list of variables indexed on their name together with the corresponding type. The declaration is echoed to the file to make the variable a normal C-variable also. The special types VARCHAR and VARCHAR2 are converted into a named struct for every variable. A declaration like: VARCHAR var[180]; is converted into struct varchar_var { int len; char arr[180]; } var; Include statements An include statement looks like: exec sql include filename; It is converted into #include <filename.h> Connect statement A connect statement looks like: exec sql connect 'database'; That statement is converted into ECPGconnect("database"); Open cursor statement An open cursor statement looks like: exec sql open cursor; and is ignore and not copied from the output. Commit statement A commit statement looks like exec sql commit; and is translated on the output to ECPGcommit(__LINE__); Rollback statement A rollback statement looks like exec sql rollback; and is translated on the output to ECPGrollback(__LINE__); Other statements Other SQL statements are other statements that start with exec sql and ends with ;. Everything inbetween is treated as an SQL statement and parsed for variable substitution. Variable substitution occur when a symbol starts with a colon (:). Then a variable with that name is found among the variables that were previously declared within a declare section and depending on whether or not the SQL statements knows it to be a variable for input or output the pointers to the variables are written to the output to allow for access by the function. For every variable that is part of the SQL request the function gets another five arguments. The type as a special symbol A pointer to the value The size of the variable if it is a varchar Number of elements in the array (for array fetches) The offset to the next element in the array (for array fetches) Since the array fetches are not implemented yet the two last arguments are not really important. They could perhaps have been left out. A Complete Example Here is a complete example describing the output 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: /* These two include files are added by the preprocessor */ #include <ecpgtype.h> #include <ecpglib.h> /* exec sql begin declare section */ int index; int result; /* exec sql end declare section */ ... ECPGdo(__LINE__, "select res from mytable where index = ;;", ECPGt_int,&index,0,0,sizeof(int), ECPGt_EOIT, ECPGt_int,&result,0,0,sizeof(int), ECPGt_EORT ); (the indentation in this manual is added for readability and not something that the preprocessor can do.) The Library The most important function in the library is the ECPGdo function. It takes a variable amount of arguments. Hopefully we wont run into machines with limits on the amount of variables that can be accepted by a varchar function. This could easily add up to 50 or so arguments. The arguments are: A line number This is a line number for the original line used in error messages only. A string This is the SQL request that is to be issued. This request is modified by the input variables, i.e. the variables that where not known at compile time but are to be entered in the request. Where the variables should go the string contains ;. Input variables As described in the section about the preprocessor every input variable gets five arguments. ECPGt_EOIT An enum telling that there are no more input variables. Output variables As described in the section about the preprocessor every input variable gets five arguments. These variables are filled by the function. ECPGt_EORT An enum telling that there are no more variables. All the SQL statements are performed in one transaction unless you issue a commit transaction. This works so that the first transaction or the first after a commit or rollback always begins a transaction. To be completed: entries describing the other entries.