EXECUTE IMMEDIATE

Description

Executes a SQL statement provided as a STRING. The statement optionally passes arguments to parameter markers and assigns the results to variables.

Syntax

EXECUTE IMMEDIATE sql_string
        [ INTO var_name [, ...] ]
        [ USING { arg_expr [ AS ] [alias] } [, ...] ]

For compatibility with other SQL dialects, EXECUTE IMMEDIATE also supports USING ( { arg_expr [ AS ] [alias] } [, ...] )

Parameters

Examples

-- A self-contained execution using a literal string
EXECUTE IMMEDIATE 'SELECT SUM(c1) FROM VALUES(?), (?) AS t(c1)' USING 5, 6;
 11

-- A SQL string composed in a SQL variable
DECLARE sqlStr = 'SELECT SUM(c1) FROM VALUES(?), (?) AS t(c1)';
DECLARE arg1 = 5;
DECLARE arg2 = 6;
EXECUTE IMMEDIATE sqlStr USING arg1, arg2;
 11

-- Using the INTO clause
DECLARE sum INT;
DECLARE sqlStr = 'SELECT SUM(c1) FROM VALUES(:first), (:second) AS t(c1)';
EXECUTE IMMEDIATE sqlStr INTO sum USING arg1, arg2;
SELECT sum;
 11

-- Using named parameter markers
DECLARE sum INT;
DECLARE sqlStr = 'SELECT SUM(c1) FROM VALUES(:first), (:second) AS t(c1)';
EXECUTE IMMEDIATE sqlStr INTO sum USING (5 AS first, arg2 AS second);
SELECT sum;
 11

-- Using constant expressions
DECLARE foo = 'sum';
EXECUTE IMMEDIATE 'SELECT ' || foo || '(c1) FROM VALUES(?), (?) AS t(c1)'
   USING 5 + 6, 7 + length('hello');
 33