File: README.execute_statement2

package info (click to toggle)
firebird3.0 3.0.13.ds7-2
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid
  • size: 42,632 kB
  • sloc: ansic: 374,403; cpp: 319,973; sql: 14,691; pascal: 14,532; yacc: 7,557; fortran: 5,645; sh: 5,336; makefile: 1,041; perl: 194; sed: 83; awk: 76; xml: 19; csh: 15
file content (261 lines) | stat: -rw-r--r-- 8,774 bytes parent folder | download | duplicates (6)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
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 <hvlad@users.sourceforge.net>
   Alex Peshkoff <pes@insi.yaroslavl.ru>


Syntax and notes :

[FOR] EXECUTE STATEMENT <query_text> [(<input_parameters>)]
    [ON EXTERNAL [DATA SOURCE] <connection_string>]
    [WITH AUTONOMOUS | COMMON TRANSACTION]
    [AS USER <user_name>]
    [PASSWORD <password>]
    [ROLE <role_name>]
    [WITH CALLER PRIVILEGES]
    [INTO <variables>]
    
- Order of clauses below is not fixed :
    [ON EXTERNAL [DATA SOURCE] <connection_string>]
    [WITH AUTONOMOUS TRANSACTION | COMMON TRANSACTION]
    [AS USER <user_name>]
    [PASSWORD <password>]
    [ROLE <role_name>]
    [WITH CALLER PRIVILEGES]
	
- Duplicate clauses are not allowed

- if you use both <query_text> and <input_parameters> then you must
    enclose <query_text> 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 
	<input_parameters> ::= 
		  <named_parameter> 
		| <input_parameters>, <named_parameter>
		
	<named_parameter> ::= 
		  <parameter name> := <expression>

	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 <user_name> equal to CURRENT_USER
	and if ROLE clause is omitted or <role_name> equal to CURRENT_ROLE
	then the statement is executed in current connection context
	c) if <user_name> is not equal to CURRENT_USER or <role_name> not equal to CURRENT_ROLE
	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).

- <connection_string> is usual connection string accepted by isc_attach_database, 
    i.e. [<host_name><protocol_delimiter>]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 PASSWORD clause is omitted then 
	a) if <user_name> is omitted, NULL or equal to CURRENT_USER value and
		if <role_name> is omitted, NULL or equal to CURRENT_ROLE value
		then trusted autentication is performed, and
		a1) for current connection (ON EXTERNAL DATA SOURCE is omitted) -
			CURRENT_USER/CURRENT_ROLE is effective user account and role
		a2) for local database (<connection_string> refers to the current database) -
			CURRENT_USER/CURRENT_ROLE is effective user account and role
		a3) for remote database - operating system account under which engine
			process is currently run is effective user account.
	b) else isc_dpb_user_name (if <user_name> is present and not empty) and isc_dpb_sql_role_name
	   (if <role_name> is present and not empty) will be filled 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.

- Exceptions handling
	a) if ON EXTERNAL DATA SOURCE clause is present then error information is interpreted 
		by the Firebird itself and wrapped into Firebird own error (isc_eds_connection or 
		isc_eds_statement). This is necessary as in general user application can't interprete
		or understand error codes provided by (unknown) external data source. Text of 
		interpreted remote error contains both error codes and corresponding messages.
		
		a1) format of isc_eds_connection error :
			Template string 
				Execute statement error at @1 :\n@2Data source : @3
			Status-vector tags
				isc_eds_connection,
				isc_arg_string, <failed API function name>,
				isc_arg_string, <text of interpreted external error>,
				isc_arg_string, <data source name>
		
		a2) format of isc_eds_statement error :
			Template string 
				Execute statement error at @1 :\n@2Statement : @3\nData source : @4
			Status-vector tags
				isc_eds_statement,
				isc_arg_string, <failed API function name>,
				isc_arg_string, <text of interpreted external error>,
				isc_arg_string, <query>,
				isc_arg_string, <data source name>
				
		At PSQL level these errors could be handled using appropriate GDS code, for example

			WHEN GDSCODE eds_statement
			
		Note, that original error codes are not accessible in WHEN statement. This could be
		improved in the future.
			
	b) if ON EXTERNAL DATA SOURCE clause is omitted then original status-vector with 
		error is passed to the caller PSQL code as is. For example, if dynamic statement
		raised isc_lock_conflict error, this error will be passed to the caller and
		could be handled using following handler
		
			WHEN GDSCODE lock_conflict
			


    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