README.execute_statement2 9.5 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296
  1. SQL Language Extension: EXECUTE STATEMENT
  2. Extends already implemented EXECUTE STATEMENT with ability to query
  3. external Firebird's databases. Introduced support for input parameters.
  4. Authors:
  5. Vlad Khorsun <[email protected]>
  6. Alex Peshkoff <[email protected]>
  7. Syntax and notes :
  8. [FOR] EXECUTE STATEMENT <query_text> [(<input_parameters>)]
  9. [ON EXTERNAL [DATA SOURCE] <connection_string>]
  10. [WITH AUTONOMOUS | COMMON TRANSACTION]
  11. [AS USER <user_name>]
  12. [PASSWORD <password>]
  13. [ROLE <role_name>]
  14. [WITH CALLER PRIVILEGES]
  15. [INTO <variables>]
  16. - Order of clauses below is not fixed :
  17. [ON EXTERNAL [DATA SOURCE] <connection_string>]
  18. [WITH AUTONOMOUS TRANSACTION | COMMON TRANSACTION]
  19. [AS USER <user_name>]
  20. [PASSWORD <password>]
  21. [ROLE <role_name>]
  22. [WITH CALLER PRIVILEGES]
  23. - Duplicate clauses are not allowed
  24. - if you use both <query_text> and <input_parameters> then you must
  25. enclose <query_text> into round brackets, for example :
  26. EXECUTE STATEMENT (:sql) (p1 := 'abc', p2 := :second_param) ...
  27. - both named and not named input parameters are supported. Mix of named and not
  28. named input parameters in the same statement is not allowed.
  29. - syntax of named input parameters
  30. <input_parameters> ::=
  31. <named_parameter>
  32. | <input_parameters>, <named_parameter>
  33. <named_parameter> ::=
  34. [EXCESS] <parameter name> := <expression>
  35. Syntax above introduced new parameter value binding operator ":=" to avoid
  36. clashes with boolean expressions.
  37. Optional "EXCESS" mark indicates that given parameter allows to be not
  38. mentioned at query text. Note, all non-excess input parameters must be used
  39. by a query.
  40. - if ON EXTERNAL DATA SOURCE clause is omitted then
  41. a) statement will be executed against current (local) database
  42. b) if AS USER clause is omitted or <user_name> equal to CURRENT_USER
  43. and if ROLE clause is omitted or <role_name> equal to CURRENT_ROLE
  44. then the statement is executed in current connection context
  45. c) if <user_name> is not equal to CURRENT_USER or <role_name> not equal to CURRENT_ROLE
  46. then the statement is executed in separate connection established inside the same
  47. engine instance (i.e. created new internal connection without Y-Valve and remote layers).
  48. - <connection_string> is usual connection string accepted by isc_attach_database,
  49. i.e. [<host_name><protocol_delimiter>]database_path.
  50. - connection to the external data source is made using the same character set as
  51. current (local) connection is used.
  52. - AUTONOMOUS TRANSACTION started new transaction with the same parameters as current
  53. transaction. This transaction will be committed if the statement is executed ok or rolled
  54. back if the statement is executed with errors.
  55. - COMMON TRANSACTION
  56. a) started new transaction with the same parameters as current transaction, or
  57. b) used already started transaction in this connection, or
  58. c) used current transaction if current connection is used.
  59. This transaction lifetime is bound to the lifetime of current (local) transaction
  60. and commits\rolled back the same way as current transaction.
  61. - by default COMMON TRANSACTION is used.
  62. - if local transaction is READ COMMITTED READ CONSISTENCY and if external data source not
  63. supported this isolation mode, then external transaction will run with CONCURRENCY
  64. isolation mode.
  65. - if PASSWORD clause is omitted then
  66. a) if <user_name> is omitted, NULL or equal to CURRENT_USER value and
  67. if <role_name> is omitted, NULL or equal to CURRENT_ROLE value
  68. then trusted autentication is performed, and
  69. a1) for current connection (ON EXTERNAL DATA SOURCE is omitted) -
  70. CURRENT_USER/CURRENT_ROLE is effective user account and role
  71. a2) for local database (<connection_string> refers to the current database) -
  72. CURRENT_USER/CURRENT_ROLE is effective user account and role
  73. a3) for remote database - operating system account under which engine
  74. process is currently run is effective user account.
  75. b) else isc_dpb_user_name (if <user_name> is present and not empty) and isc_dpb_sql_role_name
  76. (if <role_name> is present and not empty) will be filled in DPB and native autentication
  77. is performed.
  78. - if WITH CALLER PRIVILEGES is specified and ON EXTERNAL DATA SOURCE is omitted, then
  79. the statement is prepared using additional privileges of caller stored procedure or trigger
  80. (if EXECUTE STATEMENT is inside SP\trigger). This causes the same effect as if statement
  81. is executed by SP\trigger directly.
  82. - Exceptions handling
  83. a) if ON EXTERNAL DATA SOURCE clause is present then error information is interpreted
  84. by the Firebird itself and wrapped into Firebird own error (isc_eds_connection or
  85. isc_eds_statement). This is necessary as in general user application can't interpret
  86. or understand error codes provided by (unknown) external data source. Text of
  87. interpreted remote error contains both error codes and corresponding messages.
  88. a1) format of isc_eds_connection error :
  89. Template string
  90. Execute statement error at @1 :\n@2Data source : @3
  91. Status-vector tags
  92. isc_eds_connection,
  93. isc_arg_string, <failed API function name>,
  94. isc_arg_string, <text of interpreted external error>,
  95. isc_arg_string, <data source name>
  96. a2) format of isc_eds_statement error :
  97. Template string
  98. Execute statement error at @1 :\n@2Statement : @3\nData source : @4
  99. Status-vector tags
  100. isc_eds_statement,
  101. isc_arg_string, <failed API function name>,
  102. isc_arg_string, <text of interpreted external error>,
  103. isc_arg_string, <query>,
  104. isc_arg_string, <data source name>
  105. At PSQL level these errors could be handled using appropriate GDS code, for example
  106. WHEN GDSCODE eds_statement
  107. Note, that original error codes are not accessible in WHEN statement. This could be
  108. improved in the future.
  109. b) if ON EXTERNAL DATA SOURCE clause is omitted then original status-vector with
  110. error is passed to the caller PSQL code as is. For example, if dynamic statement
  111. raised isc_lock_conflict error, this error will be passed to the caller and
  112. could be handled using following handler
  113. WHEN GDSCODE lock_conflict
  114. Examples :
  115. 1. insert speed test
  116. RECREATE TABLE TTT (TRAN INT, CONN INT, ID INT);
  117. a) direct inserts
  118. EXECUTE BLOCK AS
  119. DECLARE N INT = 100000;
  120. BEGIN
  121. WHILE (N > 0) DO
  122. BEGIN
  123. INSERT INTO TTT VALUES (CURRENT_TRANSACTION, CURRENT_CONNECTION, CURRENT_TRANSACTION);
  124. N = N - 1;
  125. END
  126. END
  127. b) inserts via prepared dynamic statement using named input parameters
  128. EXECUTE BLOCK AS
  129. DECLARE S VARCHAR(255);
  130. DECLARE N INT = 100000;
  131. BEGIN
  132. S = 'INSERT INTO TTT VALUES (:a, :b, :a)';
  133. WHILE (N > 0) DO
  134. BEGIN
  135. EXECUTE STATEMENT (:S) (a := CURRENT_TRANSACTION, b := CURRENT_CONNECTION)
  136. WITH COMMON TRANSACTION;
  137. N = N - 1;
  138. END
  139. END
  140. c) inserts via prepared dynamic statement using not named input parameters
  141. EXECUTE BLOCK AS
  142. DECLARE S VARCHAR(255);
  143. DECLARE N INT = 100000;
  144. BEGIN
  145. S = 'INSERT INTO TTT VALUES (?, ?, ?)';
  146. WHILE (N > 0) DO
  147. BEGIN
  148. EXECUTE STATEMENT (:S) (CURRENT_TRANSACTION, CURRENT_CONNECTION, CURRENT_TRANSACTION);
  149. N = N - 1;
  150. END
  151. END
  152. 2. connections and transactions test
  153. a) Execute this block few times in the same transaction - it will
  154. create three new connections to the current database and reuse
  155. it in every call. Transactions are also reused.
  156. EXECUTE BLOCK RETURNS (CONN INT, TRAN INT, DB VARCHAR(255))
  157. AS
  158. DECLARE I INT = 0;
  159. DECLARE N INT = 3;
  160. DECLARE S VARCHAR(255);
  161. BEGIN
  162. SELECT A.MON$ATTACHMENT_NAME FROM MON$ATTACHMENTS A
  163. WHERE A.MON$ATTACHMENT_ID = CURRENT_CONNECTION
  164. INTO :S;
  165. WHILE (i < N) DO
  166. BEGIN
  167. DB = TRIM(CASE i - 3 * (I / 3) WHEN 0 THEN '\\.\' WHEN 1 THEN 'localhost:' ELSE '' END) || :S;
  168. FOR EXECUTE STATEMENT 'SELECT CURRENT_CONNECTION, CURRENT_TRANSACTION FROM RDB$DATABASE'
  169. ON EXTERNAL :DB
  170. AS USER CURRENT_USER PASSWORD 'masterkey' -- just for example
  171. WITH COMMON TRANSACTION
  172. INTO :CONN, :TRAN
  173. DO SUSPEND;
  174. i = i + 1;
  175. END
  176. END
  177. b) Execute this block few times in the same transaction - it will
  178. create three new connections to the current database on every call.
  179. EXECUTE BLOCK RETURNS (CONN INT, TRAN INT, DB VARCHAR(255))
  180. AS
  181. DECLARE I INT = 0;
  182. DECLARE N INT = 3;
  183. DECLARE S VARCHAR(255);
  184. BEGIN
  185. SELECT A.MON$ATTACHMENT_NAME FROM MON$ATTACHMENTS A
  186. WHERE A.MON$ATTACHMENT_ID = CURRENT_CONNECTION
  187. INTO :S;
  188. WHILE (i < N) DO
  189. BEGIN
  190. DB = TRIM(CASE i - 3 * (I / 3) WHEN 0 THEN '\\.\' WHEN 1 THEN 'localhost:' ELSE '' END) || :S;
  191. FOR EXECUTE STATEMENT 'SELECT CURRENT_CONNECTION, CURRENT_TRANSACTION FROM RDB$DATABASE'
  192. ON EXTERNAL :DB
  193. WITH AUTONOMOUS TRANSACTION -- note autonomous transaction
  194. INTO :CONN, :TRAN
  195. DO SUSPEND;
  196. i = i + 1;
  197. END
  198. END
  199. 3. input expressions evaluated only once
  200. EXECUTE BLOCK RETURNS (A INT, B INT, C INT)
  201. AS
  202. BEGIN
  203. EXECUTE STATEMENT ('SELECT CAST(:X AS INT), CAST(:X AS INT), CAST(:X AS INT) FROM RDB$DATABASE')
  204. (x := GEN_ID(G, 1))
  205. INTO :A, :B, :C;
  206. SUSPEND;
  207. END
  208. 4. Using EXCESS input parameters
  209. CREATE PROCEDURE P_EXCESS (A_ID INT, A_TRAN INT = NULL, A_CONN INT = NULL)
  210. RETURNS (ID INT, TRAN INT, CONN INT)
  211. AS
  212. DECLARE S VARCHAR(255);
  213. DECLARE W VARCHAR(255) = '';
  214. BEGIN
  215. S = 'SELECT * FROM TTT WHERE ID = :ID';
  216. IF (A_TRAN IS NOT NULL)
  217. THEN W = W || ' AND TRAN = :a';
  218. IF (A_CONN IS NOT NULL)
  219. THEN W = W || ' AND CONN = :b';
  220. IF (W <> '')
  221. THEN S = S || W;
  222. -- could raise error if TRAN or CONN is null
  223. -- FOR EXECUTE STATEMENT (:S) (a := :A_TRAN, b := A_CONN, id := A_ID)
  224. -- OK in all cases
  225. FOR EXECUTE STATEMENT (:S) (EXCESS a := :A_TRAN, EXCESS b := A_CONN, id := A_ID)
  226. INTO :ID, :TRAN, :CONN
  227. DO SUSPEND;
  228. END