Examples of EXECUTE STATEMENT
with parameters
-
With named parameters:
... DECLARE license_num VARCHAR(15); DECLARE connect_string VARCHAR (100); DECLARE stmt VARCHAR (100) = 'SELECT license ' 'FROM cars ' 'WHERE driver = :driver AND location = :loc'; BEGIN -- ... EXECUTE STATEMENT (stmt) (driver := current_driver, loc := current_location) ON EXTERNAL connect_string INTO license_num;
-
The same code with positional parameters:
DECLARE license_num VARCHAR (15); DECLARE connect_string VARCHAR (100); DECLARE stmt VARCHAR (100) = 'SELECT license ' 'FROM cars ' 'WHERE driver = ? AND location = ?'; BEGIN -- ... EXECUTE STATEMENT (stmt) (current_driver, current_location) ON EXTERNAL connect_string INTO license_num;
-
Use of
EXCESS
to allow named parameters to be unused (note: this is aFOR EXECUTE STATEMENT
):
CREATE PROCEDURE P_EXCESS (A_ID INT, A_TRAN INT = NULL, A_CONN INT = NULL)
RETURNS (ID INT, TRAN INT, CONN INT)
AS
DECLARE S VARCHAR(255) = 'SELECT * FROM TTT WHERE ID = :ID';
DECLARE W VARCHAR(255) = '';
BEGIN
IF (A_TRAN IS NOT NULL)
THEN W = W || ' AND TRAN = :a';
IF (A_CONN IS NOT NULL)
THEN W = W || ' AND CONN = :b';
IF (W <> '')
THEN S = S || W;
-- could raise error if TRAN or CONN is null
-- FOR EXECUTE STATEMENT (:S) (a := :A_TRAN, b := A_CONN, id := A_ID)
-- OK in all cases
FOR EXECUTE STATEMENT (:S) (EXCESS a := :A_TRAN, EXCESS b := A_CONN, id := A_ID)
INTO :ID, :TRAN, :CONN
DO SUSPEND;
END