SQL Language Extension: EXECUTE STATEMENT Extends already implemented EXECUTE STATEMENT with ability to query external Firebird's databases. Introduced support for input parameters. Authors: Vlad Khorsun Alex Peshkoff Syntax and notes : [FOR] EXECUTE STATEMENT [()] [ON EXTERNAL [DATA SOURCE] ] [WITH AUTONOMOUS | COMMON TRANSACTION] [AS USER ] [PASSWORD ] [WITH CALLER PRIVILEGES] [INTO ] - Order of clauses below is not fixed : [ON EXTERNAL [DATA SOURCE] ] [WITH AUTONOMOUS | COMMON TRANSACTION] [AS USER ] [PASSWORD ] [WITH CALLER PRIVILEGES] - Duplicate clauses are not allowed - if you use both and then you must enclose into round brackets, for example : EXECUTE STATEMENT (:sql) (p1 := 'abc', p2 := :second_param) ... - both named and not named input parameters are supported. Mix of named and not named input parameters in the same statement is not allowed. - syntax of named input parameters ::= | , ::= := Syntax above introduced new parameter value binding operator ":=" to avoid clashes with future boolean expressions. This syntax may be changed in release version. - if ON EXTERNAL DATA SOURCE clause is omitted then a) statement will be executed against current (local) database b) if AS USER clause is omitted or equal to CURRENT_USER then the statement is executed in current connection context c) if not equal to CURRENT_USER then the statement is executed in separate connection established inside the same engine instance (i.e. created new internal connection without Y-Valve and remote layers). - is usual connection string accepted by isc_attach_database, i.e. []database_path. - connection to the external data source is made using the same character set as current (local) connection is used. - AUTONOMOUS TRANSACTION started new transaction with the same parameters as current transaction. This transaction will be committed if the statement is executed ok or rolled back if the statement is executed with errors. - COMMON TRANSACTION a) started new transaction with the same parameters as current transaction, or b) used already started transaction in this connection, or c) used current transaction if current connection is used. This transaction lifetime is bound to the lifetime of current (local) transaction and commits\rolled back the same way as current transaction. - by default COMMON TRANSACTION is used - if AS USER clause is omitted then CURRENT_USER is used - if PASSWORD clause is omitted then a) if is omitted, NULL or equal to CURRENT_USER value then trusted autentication is performed, and a1) for current connection (ON EXTERNAL DATA SOURCE is omitted) - CURRENT_USER is effective user account a2) for local database ( refers to the current database) - CURRENT_USER is effective user account a3) for remote database - operating system account under which engine process is currently run is effective user account. b) else only isc_dpb_user_name will be present in DPB and native autentication is performed. - if WITH CALLER PRIVILEGES is specified and ON EXTERNAL DATA SOURCE is omitted, then the statement is prepared using additional privileges of caller stored procedure or trigger (if EXECUTE STATEMENT is inside SP\trigger). This causes the same effect as if statement is executed by SP\trigger directly. Examples : 1. insert speed test RECREATE TABLE TTT (TRAN INT, CONN INT, ID INT); a) direct inserts EXECUTE BLOCK AS DECLARE N INT = 100000; BEGIN WHILE (N > 0) DO BEGIN INSERT INTO TTT VALUES (CURRENT_TRANSACTION, CURRENT_CONNECTION, CURRENT_TRANSACTION); N = N - 1; END END b) inserts via prepared dynamic statement using named input parameters EXECUTE BLOCK AS DECLARE S VARCHAR(255); DECLARE N INT = 100000; BEGIN S = 'INSERT INTO TTT VALUES (:a, :b, :a)'; WHILE (N > 0) DO BEGIN EXECUTE STATEMENT (:S) (a := CURRENT_TRANSACTION, b := CURRENT_CONNECTION) WITH COMMON TRANSACTION; N = N - 1; END END c) inserts via prepared dynamic statement using not named input parameters EXECUTE BLOCK AS DECLARE S VARCHAR(255); DECLARE N INT = 100000; BEGIN S = 'INSERT INTO TTT VALUES (?, ?, ?)'; WHILE (N > 0) DO BEGIN EXECUTE STATEMENT (:S) (CURRENT_TRANSACTION, CURRENT_CONNECTION, CURRENT_TRANSACTION); N = N - 1; END END 2. connections and transactions test a) Execute this block few times in the same transaction - it will create three new connections to the current database and reuse it in every call. Transactions are also reused. EXECUTE BLOCK RETURNS (CONN INT, TRAN INT, DB VARCHAR(255)) AS DECLARE I INT = 0; DECLARE N INT = 3; DECLARE S VARCHAR(255); BEGIN SELECT A.MON$ATTACHMENT_NAME FROM MON$ATTACHMENTS A WHERE A.MON$ATTACHMENT_ID = CURRENT_CONNECTION INTO :S; WHILE (i < N) DO BEGIN DB = TRIM(CASE i - 3 * (I / 3) WHEN 0 THEN '\\.\' WHEN 1 THEN 'localhost:' ELSE '' END) || :S; FOR EXECUTE STATEMENT 'SELECT CURRENT_CONNECTION, CURRENT_TRANSACTION FROM RDB$DATABASE' ON EXTERNAL :DB AS USER CURRENT_USER PASSWORD 'masterkey' -- just for example WITH COMMON TRANSACTION INTO :CONN, :TRAN DO SUSPEND; i = i + 1; END END b) Execute this block few times in the same transaction - it will create three new connections to the current database on every call. EXECUTE BLOCK RETURNS (CONN INT, TRAN INT, DB VARCHAR(255)) AS DECLARE I INT = 0; DECLARE N INT = 3; DECLARE S VARCHAR(255); BEGIN SELECT A.MON$ATTACHMENT_NAME FROM MON$ATTACHMENTS A WHERE A.MON$ATTACHMENT_ID = CURRENT_CONNECTION INTO :S; WHILE (i < N) DO BEGIN DB = TRIM(CASE i - 3 * (I / 3) WHEN 0 THEN '\\.\' WHEN 1 THEN 'localhost:' ELSE '' END) || :S; FOR EXECUTE STATEMENT 'SELECT CURRENT_CONNECTION, CURRENT_TRANSACTION FROM RDB$DATABASE' ON EXTERNAL :DB WITH AUTONOMOUS TRANSACTION -- note autonomous transaction INTO :CONN, :TRAN DO SUSPEND; i = i + 1; END END 3. input expressions evaluated only once EXECUTE BLOCK RETURNS (A INT, B INT, C INT) AS BEGIN EXECUTE STATEMENT ('SELECT CAST(:X AS INT), CAST(:X AS INT), CAST(:X AS INT) FROM RDB$DATABASE') (x := GEN_ID(G, 1)) INTO :A, :B, :C; SUSPEND; END