Building and executing dynamic SQL statements v15
The following examples show four techniques for building and executing dynamic SQL statements. Each example shows processing a different combination of statement and input types:
- The first example shows processing and executing a SQL statement that doesn't contain a
SELECT
statement and doesn't require input variables. This example corresponds to the techniques used by Oracle Dynamic SQL Method 1. - The second example shows processing and executing a SQL statement that doesn't contain a
SELECT
statement and contains a known number of input variables. This example corresponds to the techniques used by Oracle Dynamic SQL Method 2. - The third example shows processing and executing a SQL statement that might contain a
SELECT
statement and includes a known number of input variables. This example corresponds to the techniques used by Oracle Dynamic SQL Method 3. - The fourth example shows processing and executing a SQL statement that might contain a
SELECT
statement and includes an unknown number of input variables. This example corresponds to the techniques used by Oracle Dynamic SQL Method 4.
Example: Executing a nonquery statement without parameters
This example shows how to use the EXECUTE IMMEDIATE
command to execute a SQL statement, where the text of the statement isn't known until you run the application. You can't use EXECUTE IMMEDIATE
to execute a statement that returns a result set. You can't use EXECUTE IMMEDIATE
to execute a statement that contains parameter placeholders.
The EXECUTE IMMEDIATE
statement parses and plans the SQL statement each time it executes, which can have a negative impact on the performance of your application. If you plan to execute the same statement repeatedly, consider using the PREPARE/EXECUTE
technique described in Example: Executing a nonquery statement with a specified number of placeholders.
/***********************************************************/ #include <stdio.h> #include <string.h> #include <stdlib.h> static void handle_error(void); int main(int argc, char *argv[]) { char *insertStmt; EXEC SQL WHENEVER SQLERROR DO handle_error(); EXEC SQL CONNECT :argv[1]; insertStmt = "INSERT INTO dept VALUES(50, 'ACCTG', 'SEATTLE')"; EXEC SQL EXECUTE IMMEDIATE :insertStmt; fprintf(stderr, "ok\n"); EXEC SQL COMMIT RELEASE; exit(EXIT_SUCCESS); } static void handle_error(void) { fprintf(stderr, "%s\n", sqlca.sqlerrm.sqlerrmc); EXEC SQL WHENEVER SQLERROR CONTINUE; EXEC SQL ROLLBACK RELEASE; exit(EXIT_FAILURE); } /***********************************************************/
The code sample begins by including the prototypes and type definitions for the C stdio
, string
, and stdlib
libraries and providing basic infrastructure for the program:
#include <stdio.h> #include <string.h> #include <stdlib.h> static void handle_error(void); int main(int argc, char *argv[]) { char *insertStmt;
The example then sets up an error handler. ECPGPlus calls the handle_error()
function whenever a SQL error occurs:
EXEC SQL WHENEVER SQLERROR DO handle_error();
Then, the example connects to the database using the credentials specified on the command line:
EXEC SQL CONNECT :argv[1];
Next, the program uses an EXECUTE IMMEDIATE
statement to execute a SQL statement, adding a row to the dept
table:
insertStmt = "INSERT INTO dept VALUES(50, 'ACCTG', 'SEATTLE')"; EXEC SQL EXECUTE IMMEDIATE :insertStmt;
If the EXECUTE IMMEDIATE
command fails, ECPGPlus invokes the handle_error()
function, which terminates the application after displaying an error message to the user. If the EXECUTE IMMEDIATE
command succeeds, the application displays a message (ok
) to the user, commits the changes, disconnects from the server, and terminates the application:
fprintf(stderr, "ok\n"); EXEC SQL COMMIT RELEASE; exit(EXIT_SUCCESS); }
ECPGPlus calls the handle_error()
function whenever it encounters a SQL error. The handle_error()
function prints the content of the error message, resets the error handler, rolls back any changes, disconnects from the database, and terminates the application:
static void handle_error(void) { fprintf(stderr, "%s\n", sqlca.sqlerrm.sqlerrmc); EXEC SQL WHENEVER SQLERROR CONTINUE; EXEC SQL ROLLBACK RELEASE; exit(EXIT_FAILURE); }
Example: Executing a nonquery statement with a specified number of placeholders
To execute a nonquery command that includes a known number of parameter placeholders, you must first PREPARE
the statement (providing a statement handle) and then EXECUTE
the statement using the statement handle. When the application executes the statement, it must provide a value for each placeholder found in the statement.
When an application uses the PREPARE/EXECUTE
mechanism, each SQL statement is parsed and planned once but might execute many times, providing different values each time.
ECPGPlus converts each parameter value to the type required by the SQL statement, if possible. Otherwise, ECPGPlus reports an error.
/***********************************************************/ #include <stdio.h> #include <string.h> #include <stdlib.h> #include <sqlca.h> static void handle_error(void); int main(int argc, char *argv[]) { char *stmtText; EXEC SQL WHENEVER SQLERROR DO handle_error(); EXEC SQL CONNECT :argv[1]; stmtText = "INSERT INTO dept VALUES(?, ?, ?)"; EXEC SQL PREPARE stmtHandle FROM :stmtText; EXEC SQL EXECUTE stmtHandle USING :argv[2], :argv[3], :argv[4]; fprintf(stderr, "ok\n"); EXEC SQL COMMIT RELEASE; exit(EXIT_SUCCESS); } static void handle_error(void) { printf("%s\n", sqlca.sqlerrm.sqlerrmc); EXEC SQL WHENEVER SQLERROR CONTINUE; EXEC SQL ROLLBACK RELEASE; exit(EXIT_FAILURE); } /***********************************************************/
The code sample begins by including the prototypes and type definitions for the C stdio
, string
, stdlib
, and sqlca
libraries and providing basic infrastructure for the program:
#include <stdio.h> #include <string.h> #include <stdlib.h> #include <sqlca.h> static void handle_error(void); int main(int argc, char *argv[]) { char *stmtText;
The example then sets up an error handler. ECPGPlus calls the handle_error()
function whenever a SQL error occurs.
EXEC SQL WHENEVER SQLERROR DO handle_error();
Then, the example connects to the database using the credentials specified on the command line: