File: plpgsql_transaction.sql

package info (click to toggle)
libpg-query 17-6.1.0-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid, trixie
  • size: 32,420 kB
  • sloc: ansic: 171,152; sql: 78,873; ruby: 1,547; makefile: 266; cpp: 221
file content (636 lines) | stat: -rw-r--r-- 11,395 bytes parent folder | download | duplicates (4)
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
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
CREATE TABLE test1 (a int, b text);


CREATE PROCEDURE transaction_test1(x int, y text)
LANGUAGE plpgsql
AS $$
BEGIN
    FOR i IN 0..x LOOP
        INSERT INTO test1 (a, b) VALUES (i, y);
        IF i % 2 = 0 THEN
            COMMIT;
        ELSE
            ROLLBACK;
        END IF;
    END LOOP;
END
$$;

CALL transaction_test1(9, 'foo');

SELECT * FROM test1;


TRUNCATE test1;

DO
LANGUAGE plpgsql
$$
BEGIN
    FOR i IN 0..9 LOOP
        INSERT INTO test1 (a) VALUES (i);
        IF i % 2 = 0 THEN
            COMMIT;
        ELSE
            ROLLBACK;
        END IF;
    END LOOP;
END
$$;

SELECT * FROM test1;


-- transaction commands not allowed when called in transaction block
START TRANSACTION;
CALL transaction_test1(9, 'error');
COMMIT;

START TRANSACTION;
DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$;
COMMIT;


TRUNCATE test1;

-- not allowed in a function
CREATE FUNCTION transaction_test2() RETURNS int
LANGUAGE plpgsql
AS $$
BEGIN
    FOR i IN 0..9 LOOP
        INSERT INTO test1 (a) VALUES (i);
        IF i % 2 = 0 THEN
            COMMIT;
        ELSE
            ROLLBACK;
        END IF;
    END LOOP;
    RETURN 1;
END
$$;

SELECT transaction_test2();

SELECT * FROM test1;


-- also not allowed if procedure is called from a function
CREATE FUNCTION transaction_test3() RETURNS int
LANGUAGE plpgsql
AS $$
BEGIN
    CALL transaction_test1(9, 'error');
    RETURN 1;
END;
$$;

SELECT transaction_test3();

SELECT * FROM test1;


-- DO block inside function
CREATE FUNCTION transaction_test4() RETURNS int
LANGUAGE plpgsql
AS $$
BEGIN
    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
    RETURN 1;
END;
$$;

SELECT transaction_test4();


-- proconfig settings currently disallow transaction statements
CREATE PROCEDURE transaction_test5()
LANGUAGE plpgsql
SET work_mem = 555
AS $$
BEGIN
    COMMIT;
END;
$$;

CALL transaction_test5();


-- SECURITY DEFINER currently disallow transaction statements
CREATE PROCEDURE transaction_test5b()
LANGUAGE plpgsql
SECURITY DEFINER
AS $$
BEGIN
    COMMIT;
END;
$$;

CALL transaction_test5b();


TRUNCATE test1;

-- nested procedure calls
CREATE PROCEDURE transaction_test6(c text)
LANGUAGE plpgsql
AS $$
BEGIN
    CALL transaction_test1(9, c);
END;
$$;

CALL transaction_test6('bar');

SELECT * FROM test1;

TRUNCATE test1;

CREATE PROCEDURE transaction_test7()
LANGUAGE plpgsql
AS $$
BEGIN
    DO 'BEGIN CALL transaction_test1(9, $x$baz$x$); END;';
END;
$$;

CALL transaction_test7();

SELECT * FROM test1;

CREATE PROCEDURE transaction_test8()
LANGUAGE plpgsql
AS $$
BEGIN
    EXECUTE 'CALL transaction_test1(10, $x$baz$x$)';
END;
$$;

CALL transaction_test8();


-- commit inside cursor loop
CREATE TABLE test2 (x int);
INSERT INTO test2 VALUES (0), (1), (2), (3), (4);

TRUNCATE test1;

DO LANGUAGE plpgsql $$
DECLARE
    r RECORD;
BEGIN
    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
        INSERT INTO test1 (a) VALUES (r.x);
        COMMIT;
    END LOOP;
END;
$$;

SELECT * FROM test1;

-- check that this doesn't leak a holdable portal
SELECT * FROM pg_cursors;


-- error in cursor loop with commit
TRUNCATE test1;

DO LANGUAGE plpgsql $$
DECLARE
    r RECORD;
BEGIN
    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
        INSERT INTO test1 (a) VALUES (12/(r.x-2));
        COMMIT;
    END LOOP;
END;
$$;

SELECT * FROM test1;

SELECT * FROM pg_cursors;


-- rollback inside cursor loop
TRUNCATE test1;

DO LANGUAGE plpgsql $$
DECLARE
    r RECORD;
BEGIN
    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
        INSERT INTO test1 (a) VALUES (r.x);
        ROLLBACK;
    END LOOP;
END;
$$;

SELECT * FROM test1;

SELECT * FROM pg_cursors;


-- first commit then rollback inside cursor loop
TRUNCATE test1;

DO LANGUAGE plpgsql $$
DECLARE
    r RECORD;
BEGIN
    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
        INSERT INTO test1 (a) VALUES (r.x);
        IF r.x % 2 = 0 THEN
            COMMIT;
        ELSE
            ROLLBACK;
        END IF;
    END LOOP;
END;
$$;

SELECT * FROM test1;

SELECT * FROM pg_cursors;


-- rollback inside cursor loop
TRUNCATE test1;

DO LANGUAGE plpgsql $$
DECLARE
    r RECORD;
BEGIN
    FOR r IN UPDATE test2 SET x = x * 2 RETURNING x LOOP
        INSERT INTO test1 (a) VALUES (r.x);
        ROLLBACK;
    END LOOP;
END;
$$;

SELECT * FROM test1;
SELECT * FROM test2;

SELECT * FROM pg_cursors;


-- interaction of FOR UPDATE cursor with subsequent updates (bug #17050)
TRUNCATE test1;

INSERT INTO test1 VALUES (1,'one'), (2,'two'), (3,'three');

DO LANGUAGE plpgsql $$
DECLARE
    l_cur CURSOR FOR SELECT a FROM test1 ORDER BY 1 FOR UPDATE;
BEGIN
    FOR r IN l_cur LOOP
      UPDATE test1 SET b = b || ' ' || b WHERE a = r.a;
      COMMIT;
    END LOOP;
END;
$$;

SELECT * FROM test1;

SELECT * FROM pg_cursors;


-- like bug #17050, but with implicit cursor
TRUNCATE test1;

INSERT INTO test1 VALUES (1,'one'), (2,'two'), (3,'three');

DO LANGUAGE plpgsql $$
DECLARE r RECORD;
BEGIN
    FOR r IN SELECT a FROM test1 FOR UPDATE LOOP
      UPDATE test1 SET b = b || ' ' || b WHERE a = r.a;
      COMMIT;
    END LOOP;
END;
$$;

SELECT * FROM test1;

SELECT * FROM pg_cursors;


-- commit inside block with exception handler
TRUNCATE test1;

DO LANGUAGE plpgsql $$
BEGIN
    BEGIN
        INSERT INTO test1 (a) VALUES (1);
        COMMIT;
        INSERT INTO test1 (a) VALUES (1/0);
        COMMIT;
    EXCEPTION
        WHEN division_by_zero THEN
            RAISE NOTICE 'caught division_by_zero';
    END;
END;
$$;

SELECT * FROM test1;


-- rollback inside block with exception handler
TRUNCATE test1;

DO LANGUAGE plpgsql $$
BEGIN
    BEGIN
        INSERT INTO test1 (a) VALUES (1);
        ROLLBACK;
        INSERT INTO test1 (a) VALUES (1/0);
        ROLLBACK;
    EXCEPTION
        WHEN division_by_zero THEN
            RAISE NOTICE 'caught division_by_zero';
    END;
END;
$$;

SELECT * FROM test1;


-- test commit/rollback inside exception handler, too
TRUNCATE test1;

DO LANGUAGE plpgsql $$
BEGIN
    FOR i IN 1..10 LOOP
      BEGIN
        INSERT INTO test1 VALUES (i, 'good');
        INSERT INTO test1 VALUES (i/0, 'bad');
      EXCEPTION
        WHEN division_by_zero THEN
            INSERT INTO test1 VALUES (i, 'exception');
            IF (i % 3) > 0 THEN COMMIT; ELSE ROLLBACK; END IF;
      END;
    END LOOP;
END;
$$;

SELECT * FROM test1;


-- detoast result of simple expression after commit
CREATE TEMP TABLE test4(f1 text);
ALTER TABLE test4 ALTER COLUMN f1 SET STORAGE EXTERNAL; -- disable compression
INSERT INTO test4 SELECT repeat('xyzzy', 2000);

-- immutable mark is a bit of a lie, but it serves to make call a simple expr
-- that will return a still-toasted value
CREATE FUNCTION data_source(i int) RETURNS TEXT LANGUAGE sql
AS 'select f1 from test4' IMMUTABLE;

DO $$
declare x text;
begin
  for i in 1..3 loop
    x := data_source(i);
    commit;
  end loop;
  raise notice 'length(x) = %', length(x);
end $$;


-- operations on composite types vs. internal transactions
DO LANGUAGE plpgsql $$
declare
  c test1 := row(42, 'hello');
  r bool;
begin
  for i in 1..3 loop
    r := c is not null;
    raise notice 'r = %', r;
    commit;
  end loop;
  for i in 1..3 loop
    r := c is null;
    raise notice 'r = %', r;
    rollback;
  end loop;
end
$$;


-- COMMIT failures
DO LANGUAGE plpgsql $$
BEGIN
    CREATE TABLE test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED);
    COMMIT;
    INSERT INTO test3 (y) VALUES (1);
    COMMIT;
    INSERT INTO test3 (y) VALUES (1);
    INSERT INTO test3 (y) VALUES (2);
    COMMIT;
    INSERT INTO test3 (y) VALUES (3);  -- won't get here
END;
$$;

SELECT * FROM test3;

-- failure while trying to persist a cursor across a transaction (bug #15703)
CREATE PROCEDURE cursor_fail_during_commit()
 LANGUAGE plpgsql
AS $$
  DECLARE id int;
  BEGIN
    FOR id IN SELECT 1/(x-1000) FROM generate_series(1,1000) x LOOP
        INSERT INTO test1 VALUES(id);
        COMMIT;
    END LOOP;
  END;
$$;

TRUNCATE test1;

CALL cursor_fail_during_commit();

-- note that error occurs during first COMMIT, hence nothing is in test1
SELECT count(*) FROM test1;

CREATE PROCEDURE cursor_fail_during_rollback()
 LANGUAGE plpgsql
AS $$
  DECLARE id int;
  BEGIN
    FOR id IN SELECT 1/(x-1000) FROM generate_series(1,1000) x LOOP
        INSERT INTO test1 VALUES(id);
        ROLLBACK;
    END LOOP;
  END;
$$;

TRUNCATE test1;

CALL cursor_fail_during_rollback();

SELECT count(*) FROM test1;


-- SET TRANSACTION
DO LANGUAGE plpgsql $$
BEGIN
    PERFORM 1;
    RAISE INFO '%', current_setting('transaction_isolation');
    COMMIT;
    SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
    PERFORM 1;
    RAISE INFO '%', current_setting('transaction_isolation');
    COMMIT;
    SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
    PERFORM 1;
    RAISE INFO '%', current_setting('transaction_isolation');
    COMMIT;
END;
$$;

-- error cases
DO LANGUAGE plpgsql $$
BEGIN
    SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
END;
$$;

DO LANGUAGE plpgsql $$
BEGIN
    SAVEPOINT foo;
END;
$$;

DO LANGUAGE plpgsql $$
BEGIN
    EXECUTE 'COMMIT';
END;
$$;


-- snapshot handling test
TRUNCATE test2;

CREATE PROCEDURE transaction_test9()
LANGUAGE SQL
AS $$
INSERT INTO test2 VALUES (42);
$$;

DO LANGUAGE plpgsql $$
BEGIN
  ROLLBACK;
  CALL transaction_test9();
END
$$;

SELECT * FROM test2;


-- another snapshot handling case: argument expressions of a CALL need
-- to be evaluated with an up-to-date snapshot
CREATE FUNCTION report_count() RETURNS int
STABLE LANGUAGE sql
AS $$ SELECT COUNT(*) FROM test2 $$;

CREATE PROCEDURE transaction_test9b(cnt int)
LANGUAGE plpgsql
AS $$
BEGIN
  RAISE NOTICE 'count = %', cnt;
END
$$;

DO $$
BEGIN
    CALL transaction_test9b(report_count());
    INSERT INTO test2 VALUES(43);
    CALL transaction_test9b(report_count());
END
$$;


-- Test transaction in procedure with output parameters.  This uses a
-- different portal strategy and different code paths in pquery.c.
CREATE PROCEDURE transaction_test10a(INOUT x int)
LANGUAGE plpgsql
AS $$
BEGIN
  x := x + 1;
  COMMIT;
END;
$$;

CALL transaction_test10a(10);

CREATE PROCEDURE transaction_test10b(INOUT x int)
LANGUAGE plpgsql
AS $$
BEGIN
  x := x - 1;
  ROLLBACK;
END;
$$;

CALL transaction_test10b(10);


-- transaction timestamp vs. statement timestamp
CREATE PROCEDURE transaction_test11()
LANGUAGE plpgsql
AS $$
DECLARE
  s1 timestamp with time zone;
  s2 timestamp with time zone;
  s3 timestamp with time zone;
  t1 timestamp with time zone;
  t2 timestamp with time zone;
  t3 timestamp with time zone;
BEGIN
  s1 := statement_timestamp();
  t1 := transaction_timestamp();
  ASSERT s1 = t1;
  PERFORM pg_sleep(0.001);
  COMMIT;
  s2 := statement_timestamp();
  t2 := transaction_timestamp();
  ASSERT s2 = s1;
  ASSERT t2 > t1;
  PERFORM pg_sleep(0.001);
  ROLLBACK;
  s3 := statement_timestamp();
  t3 := transaction_timestamp();
  ASSERT s3 = s1;
  ASSERT t3 > t2;
END;
$$;

CALL transaction_test11();


-- transaction chain

TRUNCATE test1;

DO LANGUAGE plpgsql $$
BEGIN
    ROLLBACK;
    SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
    FOR i IN 0..3 LOOP
        RAISE INFO 'transaction_isolation = %', current_setting('transaction_isolation');
        INSERT INTO test1 (a) VALUES (i);
        IF i % 2 = 0 THEN
            COMMIT AND CHAIN;
        ELSE
            ROLLBACK AND CHAIN;
        END IF;
    END LOOP;
END
$$;

SELECT * FROM test1;


DROP TABLE test1;
DROP TABLE test2;
DROP TABLE test3;