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
|
--
-- Tests for procedures / CALL syntax
--
CREATE PROCEDURE test_proc1()
LANGUAGE plpgsql
AS $$
BEGIN
NULL;
END;
$$;
CALL test_proc1();
-- error: can't return non-NULL
CREATE PROCEDURE test_proc2()
LANGUAGE plpgsql
AS $$
BEGIN
RETURN 5;
END;
$$;
CREATE TABLE test1 (a int);
CREATE PROCEDURE test_proc3(x int)
LANGUAGE plpgsql
AS $$
BEGIN
INSERT INTO test1 VALUES (x);
END;
$$;
CALL test_proc3(55);
SELECT * FROM test1;
-- Check that plan revalidation doesn't prevent setting transaction properties
-- (bug #18059). This test must include the first temp-object creation in
-- this script, or it won't exercise the bug scenario. Hence we put it early.
CREATE PROCEDURE test_proc3a()
LANGUAGE plpgsql
AS $$
BEGIN
COMMIT;
SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
RAISE NOTICE 'done';
END;
$$;
CALL test_proc3a();
CREATE TEMP TABLE tt1(f1 int);
CALL test_proc3a();
-- nested CALL
TRUNCATE TABLE test1;
CREATE PROCEDURE test_proc4(y int)
LANGUAGE plpgsql
AS $$
BEGIN
CALL test_proc3(y);
CALL test_proc3($1);
END;
$$;
CALL test_proc4(66);
SELECT * FROM test1;
CALL test_proc4(66);
SELECT * FROM test1;
-- output arguments
CREATE PROCEDURE test_proc5(INOUT a text)
LANGUAGE plpgsql
AS $$
BEGIN
a := a || '+' || a;
END;
$$;
CALL test_proc5('abc');
CREATE PROCEDURE test_proc6(a int, INOUT b int, INOUT c int)
LANGUAGE plpgsql
AS $$
BEGIN
b := b * a;
c := c * a;
END;
$$;
CALL test_proc6(2, 3, 4);
DO
LANGUAGE plpgsql
$$
DECLARE
x int := 3;
y int := 4;
BEGIN
CALL test_proc6(2, x, y);
RAISE INFO 'x = %, y = %', x, y;
CALL test_proc6(2, c => y, b => x);
RAISE INFO 'x = %, y = %', x, y;
END;
$$;
DO
LANGUAGE plpgsql
$$
DECLARE
x int := 3;
y int := 4;
BEGIN
CALL test_proc6(2, x + 1, y); -- error
RAISE INFO 'x = %, y = %', x, y;
END;
$$;
DO
LANGUAGE plpgsql
$$
DECLARE
x constant int := 3;
y int := 4;
BEGIN
CALL test_proc6(2, x, y); -- error because x is constant
END;
$$;
DO
LANGUAGE plpgsql
$$
DECLARE
x int := 3;
y int := 4;
BEGIN
FOR i IN 1..5 LOOP
CALL test_proc6(i, x, y);
RAISE INFO 'x = %, y = %', x, y;
END LOOP;
END;
$$;
-- recursive with output arguments
CREATE PROCEDURE test_proc7(x int, INOUT a int, INOUT b numeric)
LANGUAGE plpgsql
AS $$
BEGIN
IF x > 1 THEN
a := x / 10;
b := x / 2;
CALL test_proc7(b::int, a, b);
END IF;
END;
$$;
CALL test_proc7(100, -1, -1);
-- inner COMMIT with output arguments
CREATE PROCEDURE test_proc7c(x int, INOUT a int, INOUT b numeric)
LANGUAGE plpgsql
AS $$
BEGIN
a := x / 10;
b := x / 2;
COMMIT;
END;
$$;
CREATE PROCEDURE test_proc7cc(_x int)
LANGUAGE plpgsql
AS $$
DECLARE _a int; _b numeric;
BEGIN
CALL test_proc7c(_x, _a, _b);
RAISE NOTICE '_x: %,_a: %, _b: %', _x, _a, _b;
END
$$;
CALL test_proc7cc(10);
-- named parameters and defaults
CREATE PROCEDURE test_proc8a(INOUT a int, INOUT b int)
LANGUAGE plpgsql
AS $$
BEGIN
RAISE NOTICE 'a: %, b: %', a, b;
a := a * 10;
b := b + 10;
END;
$$;
CALL test_proc8a(10, 20);
CALL test_proc8a(b => 20, a => 10);
DO $$
DECLARE _a int; _b int;
BEGIN
_a := 10; _b := 30;
CALL test_proc8a(_a, _b);
RAISE NOTICE '_a: %, _b: %', _a, _b;
CALL test_proc8a(b => _b, a => _a);
RAISE NOTICE '_a: %, _b: %', _a, _b;
END
$$;
CREATE PROCEDURE test_proc8b(INOUT a int, INOUT b int, INOUT c int)
LANGUAGE plpgsql
AS $$
BEGIN
RAISE NOTICE 'a: %, b: %, c: %', a, b, c;
a := a * 10;
b := b + 10;
c := c * -10;
END;
$$;
DO $$
DECLARE _a int; _b int; _c int;
BEGIN
_a := 10; _b := 30; _c := 50;
CALL test_proc8b(_a, _b, _c);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
CALL test_proc8b(_a, c => _c, b => _b);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
END
$$;
CREATE PROCEDURE test_proc8c(INOUT a int, INOUT b int, INOUT c int DEFAULT 11)
LANGUAGE plpgsql
AS $$
BEGIN
RAISE NOTICE 'a: %, b: %, c: %', a, b, c;
a := a * 10;
b := b + 10;
c := c * -10;
END;
$$;
DO $$
DECLARE _a int; _b int; _c int;
BEGIN
_a := 10; _b := 30; _c := 50;
CALL test_proc8c(_a, _b, _c);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
_a := 10; _b := 30; _c := 50;
CALL test_proc8c(_a, c => _c, b => _b);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
_a := 10; _b := 30; _c := 50;
CALL test_proc8c(c => _c, b => _b, a => _a);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
END
$$;
DO $$
DECLARE _a int; _b int; _c int;
BEGIN
_a := 10; _b := 30; _c := 50;
CALL test_proc8c(_a, _b); -- fail, no output argument for c
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
END
$$;
DO $$
DECLARE _a int; _b int; _c int;
BEGIN
_a := 10; _b := 30; _c := 50;
CALL test_proc8c(_a, b => _b); -- fail, no output argument for c
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
END
$$;
-- OUT parameters
CREATE PROCEDURE test_proc9(IN a int, OUT b int)
LANGUAGE plpgsql
AS $$
BEGIN
RAISE NOTICE 'a: %, b: %', a, b;
b := a * 2;
END;
$$;
DO $$
DECLARE _a int; _b int;
BEGIN
_a := 10; _b := 30;
CALL test_proc9(_a, _b);
RAISE NOTICE '_a: %, _b: %', _a, _b;
END
$$;
CREATE PROCEDURE test_proc10(IN a int, OUT b int, IN c int DEFAULT 11)
LANGUAGE plpgsql
AS $$
BEGIN
RAISE NOTICE 'a: %, b: %, c: %', a, b, c;
b := a - c;
END;
$$;
DO $$
DECLARE _a int; _b int; _c int;
BEGIN
_a := 10; _b := 30; _c := 7;
CALL test_proc10(_a, _b, _c);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
_a := 10; _b := 30; _c := 7;
CALL test_proc10(_a, _b, c => _c);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
_a := 10; _b := 30; _c := 7;
CALL test_proc10(a => _a, b => _b, c => _c);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
_a := 10; _b := 30; _c := 7;
CALL test_proc10(_a, c => _c, b => _b);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
_a := 10; _b := 30; _c := 7;
CALL test_proc10(_a, _b);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
_a := 10; _b := 30; _c := 7;
CALL test_proc10(_a, b => _b);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
_a := 10; _b := 30; _c := 7;
CALL test_proc10(b => _b, a => _a);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
END
$$;
-- OUT + VARIADIC
CREATE PROCEDURE test_proc11(a OUT int, VARIADIC b int[])
LANGUAGE plpgsql
AS $$
BEGIN
RAISE NOTICE 'a: %, b: %', a, b;
a := b[1] + b[2];
END;
$$;
DO $$
DECLARE _a int; _b int; _c int;
BEGIN
_a := 10; _b := 30; _c := 7;
CALL test_proc11(_a, _b, _c);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
END
$$;
-- polymorphic OUT arguments
CREATE PROCEDURE test_proc12(a anyelement, OUT b anyelement, OUT c anyarray)
LANGUAGE plpgsql
AS $$
BEGIN
RAISE NOTICE 'a: %', a;
b := a;
c := array[a];
END;
$$;
DO $$
DECLARE _a int; _b int; _c int[];
BEGIN
_a := 10;
CALL test_proc12(_a, _b, _c);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
END
$$;
DO $$
DECLARE _a int; _b int; _c text[];
BEGIN
_a := 10;
CALL test_proc12(_a, _b, _c); -- error
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
END
$$;
-- transition variable assignment
TRUNCATE test1;
CREATE FUNCTION triggerfunc1() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
z int := 0;
BEGIN
CALL test_proc6(2, NEW.a, NEW.a);
RETURN NEW;
END;
$$;
CREATE TRIGGER t1 BEFORE INSERT ON test1 EXECUTE PROCEDURE triggerfunc1();
INSERT INTO test1 VALUES (1), (2), (3);
UPDATE test1 SET a = 22 WHERE a = 2;
SELECT * FROM test1 ORDER BY a;
DROP PROCEDURE test_proc1;
DROP PROCEDURE test_proc3;
DROP PROCEDURE test_proc4;
DROP TABLE test1;
-- more checks for named-parameter handling
CREATE PROCEDURE p1(v_cnt int, v_Text inout text = NULL)
AS $$
BEGIN
v_Text := 'v_cnt = ' || v_cnt;
END
$$ LANGUAGE plpgsql;
DO $$
DECLARE
v_Text text;
v_cnt integer := 42;
BEGIN
CALL p1(v_cnt := v_cnt); -- error, must supply something for v_Text
RAISE NOTICE '%', v_Text;
END;
$$;
DO $$
DECLARE
v_Text text;
v_cnt integer := 42;
BEGIN
CALL p1(v_cnt := v_cnt, v_Text := v_Text);
RAISE NOTICE '%', v_Text;
END;
$$;
DO $$
DECLARE
v_Text text;
BEGIN
CALL p1(10, v_Text := v_Text);
RAISE NOTICE '%', v_Text;
END;
$$;
DO $$
DECLARE
v_Text text;
v_cnt integer;
BEGIN
CALL p1(v_Text := v_Text, v_cnt := v_cnt);
RAISE NOTICE '%', v_Text;
END;
$$;
-- check that we detect change of dependencies in CALL
-- atomic and non-atomic call sites used to do this differently, so check both
CREATE PROCEDURE inner_p (f1 int)
AS $$
BEGIN
RAISE NOTICE 'inner_p(%)', f1;
END
$$ LANGUAGE plpgsql;
CREATE FUNCTION f(int) RETURNS int AS $$ SELECT $1 + 1 $$ LANGUAGE sql;
CREATE PROCEDURE outer_p (f1 int)
AS $$
BEGIN
RAISE NOTICE 'outer_p(%)', f1;
CALL inner_p(f(f1));
END
$$ LANGUAGE plpgsql;
CREATE FUNCTION outer_f (f1 int) RETURNS void
AS $$
BEGIN
RAISE NOTICE 'outer_f(%)', f1;
CALL inner_p(f(f1));
END
$$ LANGUAGE plpgsql;
CALL outer_p(42);
SELECT outer_f(42);
DROP FUNCTION f(int);
CREATE FUNCTION f(int) RETURNS int AS $$ SELECT $1 + 2 $$ LANGUAGE sql;
CALL outer_p(42);
SELECT outer_f(42);
-- Check that stable functions in CALL see the correct snapshot
CREATE TABLE t_test (x int);
INSERT INTO t_test VALUES (0);
CREATE FUNCTION f_get_x () RETURNS int
AS $$
DECLARE l_result int;
BEGIN
SELECT x INTO l_result FROM t_test;
RETURN l_result;
END
$$ LANGUAGE plpgsql STABLE;
CREATE PROCEDURE f_print_x (x int)
AS $$
BEGIN
RAISE NOTICE 'f_print_x(%)', x;
END
$$ LANGUAGE plpgsql;
-- test in non-atomic context
DO $$
BEGIN
UPDATE t_test SET x = x + 1;
RAISE NOTICE 'f_get_x(%)', f_get_x();
CALL f_print_x(f_get_x());
UPDATE t_test SET x = x + 1;
RAISE NOTICE 'f_get_x(%)', f_get_x();
CALL f_print_x(f_get_x());
ROLLBACK;
END
$$;
-- test in non-atomic context, except exception block is locally atomic
DO $$
BEGIN
BEGIN
UPDATE t_test SET x = x + 1;
RAISE NOTICE 'f_get_x(%)', f_get_x();
CALL f_print_x(f_get_x());
UPDATE t_test SET x = x + 1;
RAISE NOTICE 'f_get_x(%)', f_get_x();
CALL f_print_x(f_get_x());
EXCEPTION WHEN division_by_zero THEN
RAISE NOTICE '%', SQLERRM;
END;
ROLLBACK;
END
$$;
-- test in atomic context
BEGIN;
DO $$
BEGIN
UPDATE t_test SET x = x + 1;
RAISE NOTICE 'f_get_x(%)', f_get_x();
CALL f_print_x(f_get_x());
UPDATE t_test SET x = x + 1;
RAISE NOTICE 'f_get_x(%)', f_get_x();
CALL f_print_x(f_get_x());
END
$$;
ROLLBACK;
|