Extends the range of statements that can be executed from within procedures. It lets you execute dynamically prepared statements, such as statements that are constructed using the parameters passed in to a procedure.
Syntax 1
EXECUTE IMMEDIATE [ execute-option ] string-expression execute-option: WITH QUOTES [ ON | OFF ] | WITH ESCAPES { ON | OFF } | WITH RESULT SET { ON | OFF }
Syntax 2
EXECUTE ( string-expression )
WITH QUOTES is useful when an object name that is passed into the stored procedure is used to construct the statement that is to be executed, but the name might require double quotes and the procedure might be called when QUOTED_IDENTIFIER is set to OFF.
See QUOTED_IDENTIFIER Option [TSQL].
You can use WITH ESCAPES OFF for easier execution of dynamically constructed statements referencing file names that contain backslashes.
BEGIN DECLARE String1 LONG VARCHAR; DECLARE String2 LONG VARCHAR; EXECUTE IMMEDIATE 'SET String1 = ''One backslash: \\\\ '''; EXECUTE IMMEDIATE WITH ESCAPES OFF 'SET String2 = ''Two backslashes: \\\\ '''; SELECT String1, String2 END
CREATE PROCEDURE CreateTableProc( IN tablename char(30) ) BEGIN EXECUTE IMMEDIATE 'CREATE TABLE ' || tablename || ' ( column1 INT PRIMARY KEY)' END;
Call the procedure and create table mytable:
CALL CreateTableProc( 'mytable' )
Literal strings in the statement must be enclosed in single quotes, and must differ from any existing statement name in a PREPARE or EXECUTE IMMEDIATE statement. The statement must be on a single line.
Only global variables can be referenced in a statement executed by EXECUTE IMMEDIATE.
Only syntax 2 can be used inside Transact-SQL stored procedures.
Side Effects:
None. However, if the statement is a data definition statement with an automatic commit as a side effect, then that commit does take place.