EXECUTE IMMEDIATE

EXECUTE IMMEDIATE combines the basic functions of the PREPARE and EXECUTE statements. It can be used to prepare and execute an SQL statement that contains neither host variables nor parameter markers.

The EXECUTE IMMEDIATE statement:

  • Prepares an executable form of an SQL statement from a string form of the statement
  • Executes the SQL statement
  • Destroys the executable form

Invocation

This statement can only be embedded in an application program. It is an executable statement that cannot be dynamically prepared. It must not be specified in Java.

Authorization

The authorization rules are those defined for the dynamic preparation of the SQL statement specified by EXECUTE IMMEDIATE. For example, see INSERT for the authorization rules that apply when an INSERT statement is executed using EXECUTE IMMEDIATE.

Syntax

Read syntax diagram
>>-EXECUTE IMMEDIATE--+-host-variable-----+--------------------><
                      '-string-expression-'   

Description

host-variable
For languages other than PL/I, host-variable must be specified. It must identify a host variable that is described in the application program in accordance with the rules for declaring character or graphic string variables. If the source string is over 32KB in length, the host-variable must be a CLOB or DBCLOB variable. The maximum source length is 2MB although the host variable can be declared larger than 2MB. An indicator variable must not be specified. In Assembler, C, COBOL, and PL/I, the host variable must be a varying-length string variable. In C, it must not be a NUL-terminated string. In SQL PL, an SQL variable is used in place of a host variable and the value must not be null.
string-expression
string-expression is any PL/I expression that yields a string. string-expression cannot be preceded by a colon. Variables that are within string-expression that include operators or functions should not be preceded by a colon. When string-expression is specified, the precompiler-generated structures for string-expression use an EBCDIC CCSID and an informational message is returned.

Notes

Allowable SQL statements:
The value of the identified host variable or the specified string-expression is called the statement string.
The statement string must be one of the following SQL statements, and cannot be a select-statement:
ALLOCATE CURSOR
ALTER
ASSOCIATE LOCATORS
COMMENT
COMMIT
CREATE
DECLARE GLOBAL TEMPORARY
   TABLE
DELETE
DROP
EXPLAIN
FREE LOCATOR
GRANT
HOLD LOCATOR
INSERT
LABEL
LOCK TABLE
MERGE
REFRESH TABLE
RELEASE SAVEPOINT
RENAME
REVOKE
ROLLBACK
SAVEPOINT
SET CURRENT DEGREE
SET CURRENT DECFLOAT ROUNDING MODE
SET CURRENT DEBUG MODE
SET CURRENT LOCALE LC_CTYPE
SET CURRENT MAINTAINED TABLE TYPES
    FOR OPTIMIZATION
SET CURRENT OPTIMIZATION HINT
SET CURRENT PRECISION
Start of changeSET CURRENT QUERY ACCELERATIONEnd of change
SET CURRENT REFRESH AGE
SET CURRENT ROUTINE VERSION
SET CURRENT RULES
SET CURRENT SQLID
SET ENCRYPTION PASSWORD
SET PATH
SET SCHEMA
SIGNAL
TRUNCATE
UPDATE

The statement string must not:

  • Begin with EXEC SQL
  • End with END-EXEC or a semicolon
  • Include references to variables
  • Include parameter markers
Errors and error handling:
When an EXECUTE IMMEDIATE statement is executed, the specified statement string is parsed and checked for errors. If the SQL statement is invalid, it is not executed and the error condition that prevents its execution is reported in the SQLCA. If the SQL statement is valid, but an error occurs during its execution, that error condition is reported in the SQLCA.

DB2 can stop the execution of a prepared SQL statement if the statement is taking too much CPU time to finish. When this happens an error occurs. The application that issued the statement is not terminated; it is allowed to issue another SQL statement.

Start of changeEffect of the CURRENT EXPLAIN MODE special register:End of change
Start of changeIf the CURRENT EXPLAIN MODE special register is set to EXPLAIN, the statement is prepared for explain only and is not executable, unless the statement is a SET statement. Attempting to execute the prepared statement will return an error. See the CURRENT EXPLAIN MODE special register for more information.End of change
Performance considerations:
If the same SQL statement is to be executed more than once, it is more efficient to use the PREPARE and EXECUTE statements rather than the EXECUTE IMMEDIATE statement.

Examples

Example 1: In this PL/I example, the EXECUTE IMMEDIATE statement is used to execute a DELETE statement in which the rows to be deleted are determined by a search-condition specified by the value of PREDS.
EXEC SQL EXECUTE IMMEDIATE 'DELETE FROM DSN8A10.DEPT
  WHERE' || PREDS;
Example 2: Use C to execute the SQL statement in the host variable Qstring.
EXEC SQL INCLUDE SQLCA;
void main ()
  {                                                                  
   EXEC SQL BEGINDECLARE SECTION;
   char Qstring[100M =
     "INSERT INTO WORK_TABLE SELECT * FROM EMPPROJACT WHERE ACTNO >= 100";
   EXEC SQL END DECLARE SECTION; 
  .
  .
  . 
   EXEC SQL EXECUTE IMMEDIATE :Qstring;
   return; 
  }