-
Notifications
You must be signed in to change notification settings - Fork 3.8k
/
plpgsql_block
479 lines (439 loc) · 9.55 KB
/
plpgsql_block
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
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
# LogicTest: !local-mixed-23.1
statement ok
CREATE TABLE ab (a INT, b INT);
subtest nested_block
# Verify the following:
# * variables from outer blocks are visible in nested blocks
# * nested blocks can assign to variables from outer blocks
# * assignments made in nested blocks should be visible after control returns
statement ok
CREATE PROCEDURE p(x INT) AS $$
DECLARE
y INT := 10;
BEGIN
x := x + 1;
y := y + 1;
RAISE NOTICE '% %', x, y;
DECLARE
z INT := 100;
BEGIN
x := x + 1;
y := y + 1;
z := z + 1;
RAISE NOTICE '% % %', x, y, z;
END;
x := x + 1;
y := y + 1;
RAISE NOTICE '% %', x, y;
END
$$ LANGUAGE PLpgSQL;
query T noticetrace
CALL p(1);
----
NOTICE: 2 11
NOTICE: 3 12 101
NOTICE: 4 13
# Case with mutually nested blocks and IF statements, as well as RETURN
# statements within nested blocks.
statement ok
CREATE FUNCTION f(x INT) RETURNS TEXT AS $$
BEGIN
IF x = 0 THEN
RETURN 'a';
ELSIF x = 1 THEN
DECLARE
y TEXT;
BEGIN
y := 'b';
RETURN y;
END;
END IF;
DECLARE
y INT := x * 2;
BEGIN
IF y >= 10 THEN
RETURN y::TEXT;
END IF;
END;
RETURN 'c';
END
$$ LANGUAGE PLpgSQL;
query TTTT
SELECT f(0), f(1), f(2), f(5);
----
a b c 10
# Case with nested block with a loop.
statement ok
DROP PROCEDURE p;
CREATE PROCEDURE p(x INT) AS $$
BEGIN
DECLARE
i INT := 0;
BEGIN
WHILE i < x LOOP
DECLARE
j INT := 0;
BEGIN
WHILE j < i LOOP
RAISE NOTICE '%, %', i, j;
j := j + 1;
END LOOP;
RAISE NOTICE 'final j: %', j;
END;
i := i + 1;
END LOOP;
RAISE NOTICE 'final i: %', i;
END;
END
$$ LANGUAGE PLpgSQL;
query T noticetrace
CALL p(0);
----
NOTICE: final i: 0
query T noticetrace
CALL p(1);
----
NOTICE: final j: 0
NOTICE: final i: 1
query T noticetrace
CALL p(3);
----
NOTICE: final j: 0
NOTICE: 1, 0
NOTICE: final j: 1
NOTICE: 2, 0
NOTICE: 2, 1
NOTICE: final j: 2
NOTICE: final i: 3
subtest nested_block_cursors
statement ok
DROP PROCEDURE p;
CREATE PROCEDURE p() AS $$
DECLARE
curs1 CURSOR FOR SELECT 1 FROM generate_series(1, 10);
curs2 CURSOR FOR SELECT 2 FROM generate_series(1, 10);
curs3 REFCURSOR;
curs4 REFCURSOR;
scratch INT;
BEGIN
OPEN curs1;
OPEN curs3 FOR SELECT 3 FROM generate_series(1, 10);
RAISE NOTICE 'a%', scratch;
FETCH curs1 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs3 INTO scratch;
RAISE NOTICE 'a%', scratch;
DECLARE
curs5 CURSOR FOR SELECT 5 FROM generate_series(1, 10);
curs6 REFCURSOR;
BEGIN
OPEN curs2;
OPEN curs4 FOR SELECT 4 FROM generate_series(1, 10);
OPEN curs5;
OPEN curs6 FOR SELECT 6 FROM generate_series(1, 10);
FETCH curs1 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs2 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs3 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs4 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs5 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs6 INTO scratch;
RAISE NOTICE 'a%', scratch;
END;
BEGIN
FETCH curs1 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs2 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs3 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs4 INTO scratch;
RAISE NOTICE 'a%', scratch;
END;
FETCH curs1 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs2 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs3 INTO scratch;
RAISE NOTICE 'a%', scratch;
FETCH curs4 INTO scratch;
RAISE NOTICE 'a%', scratch;
END
$$ LANGUAGE PLpgSQL;
query T noticetrace
CALL p();
----
NOTICE: a<NULL>
NOTICE: a1
NOTICE: a3
NOTICE: a1
NOTICE: a2
NOTICE: a3
NOTICE: a4
NOTICE: a5
NOTICE: a6
NOTICE: a1
NOTICE: a2
NOTICE: a3
NOTICE: a4
NOTICE: a1
NOTICE: a2
NOTICE: a3
NOTICE: a4
subtest nested_block_exceptions
# Don't catch an exception thrown from the variable declarations.
statement ok
DROP PROCEDURE p;
CREATE PROCEDURE p() AS $$
DECLARE
x INT := 0;
BEGIN
RAISE NOTICE '%', x;
DECLARE
y INT := 1 // x;
BEGIN
RAISE NOTICE '% %', x, y;
EXCEPTION
WHEN division_by_zero THEN
RAISE NOTICE 'oops!';
END;
END
$$ LANGUAGE PLpgSQL;
statement error pgcode 22012 pq: division by zero
CALL p();
# Catch an exception thrown from the nested block's body statements.
statement ok
DROP PROCEDURE p;
CREATE PROCEDURE p() AS $$
DECLARE
x INT := 0;
BEGIN
RAISE NOTICE '%', x;
DECLARE
y INT;
BEGIN
y := 1 // x;
RAISE NOTICE '% %', x, y;
EXCEPTION
WHEN division_by_zero THEN
RAISE NOTICE 'oops!';
END;
END
$$ LANGUAGE PLpgSQL;
query T noticetrace
CALL p();
----
NOTICE: 0
NOTICE: oops!
# If an exception is thrown and caught within an inner block, the outer block
# is not rolled back, and execution can continue.
statement ok
DROP PROCEDURE p;
CREATE PROCEDURE p() AS $$
BEGIN
INSERT INTO ab VALUES (1, 2);
BEGIN
INSERT INTO ab VALUES (3, 4);
SELECT 1 // 0;
INSERT INTO ab VALUES (5, 6);
EXCEPTION WHEN division_by_zero THEN
RAISE NOTICE 'saw exception';
END;
INSERT INTO ab VALUES (7, 8);
RAISE NOTICE 'finished execution of outer block';
END
$$ LANGUAGE PLpgSQL;
query II rowsort
SELECT * FROM ab;
----
query T noticetrace
CALL p()
----
NOTICE: saw exception
NOTICE: finished execution of outer block
query II rowsort
SELECT * FROM ab;
----
1 2
7 8
# A variable assignment within a nested block's exception handler should be
# visible when control returns to the outer block.
statement ok
DROP PROCEDURE p;
CREATE PROCEDURE p() AS $$
DECLARE
x INT := 0;
BEGIN
RAISE NOTICE '%', x;
BEGIN
SELECT 1 // 0;
EXCEPTION
WHEN division_by_zero THEN
x := 100;
END;
RAISE NOTICE '%', x;
END
$$ LANGUAGE PLpgSQL;
query T noticetrace
CALL p();
----
NOTICE: 0
NOTICE: 100
# Cursors opened in a nested block should be closed when the block handles an
# exception. Cursors opened in the outer block should remain open.
# A cursor opened in a nested block's exception handler should be visible
# in the outer block.
statement ok
DROP PROCEDURE p;
CREATE PROCEDURE p(x INT) AS $$
DECLARE
curs1 REFCURSOR;
curs2 REFCURSOR;
curs3 REFCURSOR;
BEGIN
OPEN curs1 FOR SELECT 1;
BEGIN
OPEN curs2 FOR SELECT 2;
SELECT 1 // 0;
EXCEPTION
WHEN division_by_zero THEN
OPEN curs3 FOR SELECT 3;
END;
IF x = 1 THEN
FETCH curs1 INTO x;
ELSIF x = 2 THEN
FETCH curs2 INTO x;
ELSE
FETCH curs3 INTO x;
END IF;
RAISE NOTICE '%', x;
END
$$ LANGUAGE PLpgSQL;
query T noticetrace
CALL p(1);
----
NOTICE: 1
statement error pgcode 34000 pq: cursor \"<unnamed portal 11>\" does not exist
CALL p(2);
query T noticetrace
CALL p(3);
----
NOTICE: 3
# A block can be nested in an exception handler.
statement ok
DROP PROCEDURE p;
CREATE PROCEDURE p() AS $$
BEGIN
BEGIN
SELECT 1 // 0;
EXCEPTION
WHEN division_by_zero THEN
RAISE NOTICE 'outer handler';
DECLARE
x INT := 100;
BEGIN
RAISE NOTICE 'inner block x=%', x;
END;
END;
END
$$ LANGUAGE PLpgSQL;
query T noticetrace
CALL p();
----
NOTICE: outer handler
NOTICE: inner block 100
# A block nested in an exception handler can have its own exception handler.
statement ok
DROP PROCEDURE p;
CREATE PROCEDURE p() AS $$
BEGIN
BEGIN
SELECT 1 // 0;
EXCEPTION
WHEN division_by_zero THEN
RAISE NOTICE 'outer handler';
DECLARE
x INT := 100;
BEGIN
RAISE NOTICE 'inner block';
SELECT 1 // 0;
EXCEPTION WHEN division_by_zero THEN
RAISE NOTICE 'inner handler x=%', x;
END;
END;
END
$$ LANGUAGE PLpgSQL;
query T noticetrace
CALL p();
----
NOTICE: outer handler
NOTICE: inner block
NOTICE: inner handler 100
subtest error
statement ok
DROP PROCEDURE IF EXISTS p();
DROP FUNCTION IF EXISTS f();
# Detect duplicate declarations in a block.
statement error pgcode 42601 pq: duplicate declaration at or near \"x\"
CREATE PROCEDURE p() AS $$
DECLARE
x INT := 0;
x INT := 1;
BEGIN
RAISE NOTICE '%', x;
END
$$ LANGUAGE PLpgSQL;
# A variable declared in an inner block falls out of scope when control returns
# to the outer block.
statement error pgcode 42703 pq: column \"y\" does not exist
CREATE PROCEDURE p() AS $$
DECLARE
x INT := 0;
BEGIN
DECLARE
y INT := 1;
BEGIN
RAISE NOTICE '% %', x, y;
END;
RAISE NOTICE '% %', x, y;
END
$$ LANGUAGE PLpgSQL;
subtest unimplemented
statement ok
DROP PROCEDURE IF EXISTS p;
# Variable shadowing is not yet allowed (tracked in #117508).
statement error pgcode 0A000 pq: unimplemented: variable shadowing is not yet implemented
CREATE PROCEDURE p() AS $$
DECLARE
x INT := 0;
BEGIN
DECLARE
x INT := 1;
BEGIN
RAISE NOTICE '%', x;
END;
END
$$ LANGUAGE PLpgSQL;
# A block cannot currently be nested in a block with an exception handler
# (tracked in #foo).
statement error pgcode 0A000 pq: unimplemented: PL/pgSQL blocks cannot yet be nested within a block that has an exception handler
CREATE PROCEDURE p() AS $$
DECLARE
x INT := 0;
BEGIN
RAISE NOTICE '%', x;
DECLARE
y INT := 1 // x;
BEGIN
RAISE NOTICE '% %', x, y;
END;
EXCEPTION
WHEN division_by_zero THEN
RAISE NOTICE 'oops!';
END
$$ LANGUAGE PLpgSQL;
subtest end