1-- 2-- PLPGSQL 3-- 4-- Scenario: 5-- 6-- A building with a modern TP cable installation where any 7-- of the wall connectors can be used to plug in phones, 8-- ethernet interfaces or local office hubs. The backside 9-- of the wall connectors is wired to one of several patch- 10-- fields in the building. 11-- 12-- In the patchfields, there are hubs and all the slots 13-- representing the wall connectors. In addition there are 14-- slots that can represent a phone line from the central 15-- phone system. 16-- 17-- Triggers ensure consistency of the patching information. 18-- 19-- Functions are used to build up powerful views that let 20-- you look behind the wall when looking at a patchfield 21-- or into a room. 22-- 23 24 25create table Room ( 26 roomno char(8), 27 comment text 28); 29 30create unique index Room_rno on Room using btree (roomno bpchar_ops); 31 32 33create table WSlot ( 34 slotname char(20), 35 roomno char(8), 36 slotlink char(20), 37 backlink char(20) 38); 39 40create unique index WSlot_name on WSlot using btree (slotname bpchar_ops); 41 42 43create table PField ( 44 name text, 45 comment text 46); 47 48create unique index PField_name on PField using btree (name text_ops); 49 50 51create table PSlot ( 52 slotname char(20), 53 pfname text, 54 slotlink char(20), 55 backlink char(20) 56); 57 58create unique index PSlot_name on PSlot using btree (slotname bpchar_ops); 59 60 61create table PLine ( 62 slotname char(20), 63 phonenumber char(20), 64 comment text, 65 backlink char(20) 66); 67 68create unique index PLine_name on PLine using btree (slotname bpchar_ops); 69 70 71create table Hub ( 72 name char(14), 73 comment text, 74 nslots integer 75); 76 77create unique index Hub_name on Hub using btree (name bpchar_ops); 78 79 80create table HSlot ( 81 slotname char(20), 82 hubname char(14), 83 slotno integer, 84 slotlink char(20) 85); 86 87create unique index HSlot_name on HSlot using btree (slotname bpchar_ops); 88create index HSlot_hubname on HSlot using btree (hubname bpchar_ops); 89 90 91create table System ( 92 name text, 93 comment text 94); 95 96create unique index System_name on System using btree (name text_ops); 97 98 99create table IFace ( 100 slotname char(20), 101 sysname text, 102 ifname text, 103 slotlink char(20) 104); 105 106create unique index IFace_name on IFace using btree (slotname bpchar_ops); 107 108 109create table PHone ( 110 slotname char(20), 111 comment text, 112 slotlink char(20) 113); 114 115create unique index PHone_name on PHone using btree (slotname bpchar_ops); 116 117 118-- ************************************************************ 119-- * 120-- * Trigger procedures and functions for the patchfield 121-- * test of PL/pgSQL 122-- * 123-- ************************************************************ 124 125 126-- ************************************************************ 127-- * AFTER UPDATE on Room 128-- * - If room no changes let wall slots follow 129-- ************************************************************ 130create function tg_room_au() returns trigger as ' 131begin 132 if new.roomno != old.roomno then 133 update WSlot set roomno = new.roomno where roomno = old.roomno; 134 end if; 135 return new; 136end; 137' language plpgsql; 138 139create trigger tg_room_au after update 140 on Room for each row execute procedure tg_room_au(); 141 142 143-- ************************************************************ 144-- * AFTER DELETE on Room 145-- * - delete wall slots in this room 146-- ************************************************************ 147create function tg_room_ad() returns trigger as ' 148begin 149 delete from WSlot where roomno = old.roomno; 150 return old; 151end; 152' language plpgsql; 153 154create trigger tg_room_ad after delete 155 on Room for each row execute procedure tg_room_ad(); 156 157 158-- ************************************************************ 159-- * BEFORE INSERT or UPDATE on WSlot 160-- * - Check that room exists 161-- ************************************************************ 162create function tg_wslot_biu() returns trigger as $$ 163begin 164 if count(*) = 0 from Room where roomno = new.roomno then 165 raise exception 'Room % does not exist', new.roomno; 166 end if; 167 return new; 168end; 169$$ language plpgsql; 170 171create trigger tg_wslot_biu before insert or update 172 on WSlot for each row execute procedure tg_wslot_biu(); 173 174 175-- ************************************************************ 176-- * AFTER UPDATE on PField 177-- * - Let PSlots of this field follow 178-- ************************************************************ 179create function tg_pfield_au() returns trigger as ' 180begin 181 if new.name != old.name then 182 update PSlot set pfname = new.name where pfname = old.name; 183 end if; 184 return new; 185end; 186' language plpgsql; 187 188create trigger tg_pfield_au after update 189 on PField for each row execute procedure tg_pfield_au(); 190 191 192-- ************************************************************ 193-- * AFTER DELETE on PField 194-- * - Remove all slots of this patchfield 195-- ************************************************************ 196create function tg_pfield_ad() returns trigger as ' 197begin 198 delete from PSlot where pfname = old.name; 199 return old; 200end; 201' language plpgsql; 202 203create trigger tg_pfield_ad after delete 204 on PField for each row execute procedure tg_pfield_ad(); 205 206 207-- ************************************************************ 208-- * BEFORE INSERT or UPDATE on PSlot 209-- * - Ensure that our patchfield does exist 210-- ************************************************************ 211create function tg_pslot_biu() returns trigger as $proc$ 212declare 213 pfrec record; 214 ps alias for new; 215begin 216 select into pfrec * from PField where name = ps.pfname; 217 if not found then 218 raise exception $$Patchfield "%" does not exist$$, ps.pfname; 219 end if; 220 return ps; 221end; 222$proc$ language plpgsql; 223 224create trigger tg_pslot_biu before insert or update 225 on PSlot for each row execute procedure tg_pslot_biu(); 226 227 228-- ************************************************************ 229-- * AFTER UPDATE on System 230-- * - If system name changes let interfaces follow 231-- ************************************************************ 232create function tg_system_au() returns trigger as ' 233begin 234 if new.name != old.name then 235 update IFace set sysname = new.name where sysname = old.name; 236 end if; 237 return new; 238end; 239' language plpgsql; 240 241create trigger tg_system_au after update 242 on System for each row execute procedure tg_system_au(); 243 244 245-- ************************************************************ 246-- * BEFORE INSERT or UPDATE on IFace 247-- * - set the slotname to IF.sysname.ifname 248-- ************************************************************ 249create function tg_iface_biu() returns trigger as $$ 250declare 251 sname text; 252 sysrec record; 253begin 254 select into sysrec * from system where name = new.sysname; 255 if not found then 256 raise exception $q$system "%" does not exist$q$, new.sysname; 257 end if; 258 sname := 'IF.' || new.sysname; 259 sname := sname || '.'; 260 sname := sname || new.ifname; 261 if length(sname) > 20 then 262 raise exception 'IFace slotname "%" too long (20 char max)', sname; 263 end if; 264 new.slotname := sname; 265 return new; 266end; 267$$ language plpgsql; 268 269create trigger tg_iface_biu before insert or update 270 on IFace for each row execute procedure tg_iface_biu(); 271 272 273-- ************************************************************ 274-- * AFTER INSERT or UPDATE or DELETE on Hub 275-- * - insert/delete/rename slots as required 276-- ************************************************************ 277create function tg_hub_a() returns trigger as ' 278declare 279 hname text; 280 dummy integer; 281begin 282 if tg_op = ''INSERT'' then 283 dummy := tg_hub_adjustslots(new.name, 0, new.nslots); 284 return new; 285 end if; 286 if tg_op = ''UPDATE'' then 287 if new.name != old.name then 288 update HSlot set hubname = new.name where hubname = old.name; 289 end if; 290 dummy := tg_hub_adjustslots(new.name, old.nslots, new.nslots); 291 return new; 292 end if; 293 if tg_op = ''DELETE'' then 294 dummy := tg_hub_adjustslots(old.name, old.nslots, 0); 295 return old; 296 end if; 297end; 298' language plpgsql; 299 300create trigger tg_hub_a after insert or update or delete 301 on Hub for each row execute procedure tg_hub_a(); 302 303 304-- ************************************************************ 305-- * Support function to add/remove slots of Hub 306-- ************************************************************ 307create function tg_hub_adjustslots(hname bpchar, 308 oldnslots integer, 309 newnslots integer) 310returns integer as ' 311begin 312 if newnslots = oldnslots then 313 return 0; 314 end if; 315 if newnslots < oldnslots then 316 delete from HSlot where hubname = hname and slotno > newnslots; 317 return 0; 318 end if; 319 for i in oldnslots + 1 .. newnslots loop 320 insert into HSlot (slotname, hubname, slotno, slotlink) 321 values (''HS.dummy'', hname, i, ''''); 322 end loop; 323 return 0; 324end 325' language plpgsql; 326 327-- Test comments 328COMMENT ON FUNCTION tg_hub_adjustslots_wrong(bpchar, integer, integer) IS 'function with args'; 329COMMENT ON FUNCTION tg_hub_adjustslots(bpchar, integer, integer) IS 'function with args'; 330COMMENT ON FUNCTION tg_hub_adjustslots(bpchar, integer, integer) IS NULL; 331 332-- ************************************************************ 333-- * BEFORE INSERT or UPDATE on HSlot 334-- * - prevent from manual manipulation 335-- * - set the slotname to HS.hubname.slotno 336-- ************************************************************ 337create function tg_hslot_biu() returns trigger as ' 338declare 339 sname text; 340 xname HSlot.slotname%TYPE; 341 hubrec record; 342begin 343 select into hubrec * from Hub where name = new.hubname; 344 if not found then 345 raise exception ''no manual manipulation of HSlot''; 346 end if; 347 if new.slotno < 1 or new.slotno > hubrec.nslots then 348 raise exception ''no manual manipulation of HSlot''; 349 end if; 350 if tg_op = ''UPDATE'' and new.hubname != old.hubname then 351 if count(*) > 0 from Hub where name = old.hubname then 352 raise exception ''no manual manipulation of HSlot''; 353 end if; 354 end if; 355 sname := ''HS.'' || trim(new.hubname); 356 sname := sname || ''.''; 357 sname := sname || new.slotno::text; 358 if length(sname) > 20 then 359 raise exception ''HSlot slotname "%" too long (20 char max)'', sname; 360 end if; 361 new.slotname := sname; 362 return new; 363end; 364' language plpgsql; 365 366create trigger tg_hslot_biu before insert or update 367 on HSlot for each row execute procedure tg_hslot_biu(); 368 369 370-- ************************************************************ 371-- * BEFORE DELETE on HSlot 372-- * - prevent from manual manipulation 373-- ************************************************************ 374create function tg_hslot_bd() returns trigger as ' 375declare 376 hubrec record; 377begin 378 select into hubrec * from Hub where name = old.hubname; 379 if not found then 380 return old; 381 end if; 382 if old.slotno > hubrec.nslots then 383 return old; 384 end if; 385 raise exception ''no manual manipulation of HSlot''; 386end; 387' language plpgsql; 388 389create trigger tg_hslot_bd before delete 390 on HSlot for each row execute procedure tg_hslot_bd(); 391 392 393-- ************************************************************ 394-- * BEFORE INSERT on all slots 395-- * - Check name prefix 396-- ************************************************************ 397create function tg_chkslotname() returns trigger as ' 398begin 399 if substr(new.slotname, 1, 2) != tg_argv[0] then 400 raise exception ''slotname must begin with %'', tg_argv[0]; 401 end if; 402 return new; 403end; 404' language plpgsql; 405 406create trigger tg_chkslotname before insert 407 on PSlot for each row execute procedure tg_chkslotname('PS'); 408 409create trigger tg_chkslotname before insert 410 on WSlot for each row execute procedure tg_chkslotname('WS'); 411 412create trigger tg_chkslotname before insert 413 on PLine for each row execute procedure tg_chkslotname('PL'); 414 415create trigger tg_chkslotname before insert 416 on IFace for each row execute procedure tg_chkslotname('IF'); 417 418create trigger tg_chkslotname before insert 419 on PHone for each row execute procedure tg_chkslotname('PH'); 420 421 422-- ************************************************************ 423-- * BEFORE INSERT or UPDATE on all slots with slotlink 424-- * - Set slotlink to empty string if NULL value given 425-- ************************************************************ 426create function tg_chkslotlink() returns trigger as ' 427begin 428 if new.slotlink isnull then 429 new.slotlink := ''''; 430 end if; 431 return new; 432end; 433' language plpgsql; 434 435create trigger tg_chkslotlink before insert or update 436 on PSlot for each row execute procedure tg_chkslotlink(); 437 438create trigger tg_chkslotlink before insert or update 439 on WSlot for each row execute procedure tg_chkslotlink(); 440 441create trigger tg_chkslotlink before insert or update 442 on IFace for each row execute procedure tg_chkslotlink(); 443 444create trigger tg_chkslotlink before insert or update 445 on HSlot for each row execute procedure tg_chkslotlink(); 446 447create trigger tg_chkslotlink before insert or update 448 on PHone for each row execute procedure tg_chkslotlink(); 449 450 451-- ************************************************************ 452-- * BEFORE INSERT or UPDATE on all slots with backlink 453-- * - Set backlink to empty string if NULL value given 454-- ************************************************************ 455create function tg_chkbacklink() returns trigger as ' 456begin 457 if new.backlink isnull then 458 new.backlink := ''''; 459 end if; 460 return new; 461end; 462' language plpgsql; 463 464create trigger tg_chkbacklink before insert or update 465 on PSlot for each row execute procedure tg_chkbacklink(); 466 467create trigger tg_chkbacklink before insert or update 468 on WSlot for each row execute procedure tg_chkbacklink(); 469 470create trigger tg_chkbacklink before insert or update 471 on PLine for each row execute procedure tg_chkbacklink(); 472 473 474-- ************************************************************ 475-- * BEFORE UPDATE on PSlot 476-- * - do delete/insert instead of update if name changes 477-- ************************************************************ 478create function tg_pslot_bu() returns trigger as ' 479begin 480 if new.slotname != old.slotname then 481 delete from PSlot where slotname = old.slotname; 482 insert into PSlot ( 483 slotname, 484 pfname, 485 slotlink, 486 backlink 487 ) values ( 488 new.slotname, 489 new.pfname, 490 new.slotlink, 491 new.backlink 492 ); 493 return null; 494 end if; 495 return new; 496end; 497' language plpgsql; 498 499create trigger tg_pslot_bu before update 500 on PSlot for each row execute procedure tg_pslot_bu(); 501 502 503-- ************************************************************ 504-- * BEFORE UPDATE on WSlot 505-- * - do delete/insert instead of update if name changes 506-- ************************************************************ 507create function tg_wslot_bu() returns trigger as ' 508begin 509 if new.slotname != old.slotname then 510 delete from WSlot where slotname = old.slotname; 511 insert into WSlot ( 512 slotname, 513 roomno, 514 slotlink, 515 backlink 516 ) values ( 517 new.slotname, 518 new.roomno, 519 new.slotlink, 520 new.backlink 521 ); 522 return null; 523 end if; 524 return new; 525end; 526' language plpgsql; 527 528create trigger tg_wslot_bu before update 529 on WSlot for each row execute procedure tg_Wslot_bu(); 530 531 532-- ************************************************************ 533-- * BEFORE UPDATE on PLine 534-- * - do delete/insert instead of update if name changes 535-- ************************************************************ 536create function tg_pline_bu() returns trigger as ' 537begin 538 if new.slotname != old.slotname then 539 delete from PLine where slotname = old.slotname; 540 insert into PLine ( 541 slotname, 542 phonenumber, 543 comment, 544 backlink 545 ) values ( 546 new.slotname, 547 new.phonenumber, 548 new.comment, 549 new.backlink 550 ); 551 return null; 552 end if; 553 return new; 554end; 555' language plpgsql; 556 557create trigger tg_pline_bu before update 558 on PLine for each row execute procedure tg_pline_bu(); 559 560 561-- ************************************************************ 562-- * BEFORE UPDATE on IFace 563-- * - do delete/insert instead of update if name changes 564-- ************************************************************ 565create function tg_iface_bu() returns trigger as ' 566begin 567 if new.slotname != old.slotname then 568 delete from IFace where slotname = old.slotname; 569 insert into IFace ( 570 slotname, 571 sysname, 572 ifname, 573 slotlink 574 ) values ( 575 new.slotname, 576 new.sysname, 577 new.ifname, 578 new.slotlink 579 ); 580 return null; 581 end if; 582 return new; 583end; 584' language plpgsql; 585 586create trigger tg_iface_bu before update 587 on IFace for each row execute procedure tg_iface_bu(); 588 589 590-- ************************************************************ 591-- * BEFORE UPDATE on HSlot 592-- * - do delete/insert instead of update if name changes 593-- ************************************************************ 594create function tg_hslot_bu() returns trigger as ' 595begin 596 if new.slotname != old.slotname or new.hubname != old.hubname then 597 delete from HSlot where slotname = old.slotname; 598 insert into HSlot ( 599 slotname, 600 hubname, 601 slotno, 602 slotlink 603 ) values ( 604 new.slotname, 605 new.hubname, 606 new.slotno, 607 new.slotlink 608 ); 609 return null; 610 end if; 611 return new; 612end; 613' language plpgsql; 614 615create trigger tg_hslot_bu before update 616 on HSlot for each row execute procedure tg_hslot_bu(); 617 618 619-- ************************************************************ 620-- * BEFORE UPDATE on PHone 621-- * - do delete/insert instead of update if name changes 622-- ************************************************************ 623create function tg_phone_bu() returns trigger as ' 624begin 625 if new.slotname != old.slotname then 626 delete from PHone where slotname = old.slotname; 627 insert into PHone ( 628 slotname, 629 comment, 630 slotlink 631 ) values ( 632 new.slotname, 633 new.comment, 634 new.slotlink 635 ); 636 return null; 637 end if; 638 return new; 639end; 640' language plpgsql; 641 642create trigger tg_phone_bu before update 643 on PHone for each row execute procedure tg_phone_bu(); 644 645 646-- ************************************************************ 647-- * AFTER INSERT or UPDATE or DELETE on slot with backlink 648-- * - Ensure that the opponent correctly points back to us 649-- ************************************************************ 650create function tg_backlink_a() returns trigger as ' 651declare 652 dummy integer; 653begin 654 if tg_op = ''INSERT'' then 655 if new.backlink != '''' then 656 dummy := tg_backlink_set(new.backlink, new.slotname); 657 end if; 658 return new; 659 end if; 660 if tg_op = ''UPDATE'' then 661 if new.backlink != old.backlink then 662 if old.backlink != '''' then 663 dummy := tg_backlink_unset(old.backlink, old.slotname); 664 end if; 665 if new.backlink != '''' then 666 dummy := tg_backlink_set(new.backlink, new.slotname); 667 end if; 668 else 669 if new.slotname != old.slotname and new.backlink != '''' then 670 dummy := tg_slotlink_set(new.backlink, new.slotname); 671 end if; 672 end if; 673 return new; 674 end if; 675 if tg_op = ''DELETE'' then 676 if old.backlink != '''' then 677 dummy := tg_backlink_unset(old.backlink, old.slotname); 678 end if; 679 return old; 680 end if; 681end; 682' language plpgsql; 683 684 685create trigger tg_backlink_a after insert or update or delete 686 on PSlot for each row execute procedure tg_backlink_a('PS'); 687 688create trigger tg_backlink_a after insert or update or delete 689 on WSlot for each row execute procedure tg_backlink_a('WS'); 690 691create trigger tg_backlink_a after insert or update or delete 692 on PLine for each row execute procedure tg_backlink_a('PL'); 693 694 695-- ************************************************************ 696-- * Support function to set the opponents backlink field 697-- * if it does not already point to the requested slot 698-- ************************************************************ 699create function tg_backlink_set(myname bpchar, blname bpchar) 700returns integer as ' 701declare 702 mytype char(2); 703 link char(4); 704 rec record; 705begin 706 mytype := substr(myname, 1, 2); 707 link := mytype || substr(blname, 1, 2); 708 if link = ''PLPL'' then 709 raise exception 710 ''backlink between two phone lines does not make sense''; 711 end if; 712 if link in (''PLWS'', ''WSPL'') then 713 raise exception 714 ''direct link of phone line to wall slot not permitted''; 715 end if; 716 if mytype = ''PS'' then 717 select into rec * from PSlot where slotname = myname; 718 if not found then 719 raise exception ''% does not exist'', myname; 720 end if; 721 if rec.backlink != blname then 722 update PSlot set backlink = blname where slotname = myname; 723 end if; 724 return 0; 725 end if; 726 if mytype = ''WS'' then 727 select into rec * from WSlot where slotname = myname; 728 if not found then 729 raise exception ''% does not exist'', myname; 730 end if; 731 if rec.backlink != blname then 732 update WSlot set backlink = blname where slotname = myname; 733 end if; 734 return 0; 735 end if; 736 if mytype = ''PL'' then 737 select into rec * from PLine where slotname = myname; 738 if not found then 739 raise exception ''% does not exist'', myname; 740 end if; 741 if rec.backlink != blname then 742 update PLine set backlink = blname where slotname = myname; 743 end if; 744 return 0; 745 end if; 746 raise exception ''illegal backlink beginning with %'', mytype; 747end; 748' language plpgsql; 749 750 751-- ************************************************************ 752-- * Support function to clear out the backlink field if 753-- * it still points to specific slot 754-- ************************************************************ 755create function tg_backlink_unset(bpchar, bpchar) 756returns integer as ' 757declare 758 myname alias for $1; 759 blname alias for $2; 760 mytype char(2); 761 rec record; 762begin 763 mytype := substr(myname, 1, 2); 764 if mytype = ''PS'' then 765 select into rec * from PSlot where slotname = myname; 766 if not found then 767 return 0; 768 end if; 769 if rec.backlink = blname then 770 update PSlot set backlink = '''' where slotname = myname; 771 end if; 772 return 0; 773 end if; 774 if mytype = ''WS'' then 775 select into rec * from WSlot where slotname = myname; 776 if not found then 777 return 0; 778 end if; 779 if rec.backlink = blname then 780 update WSlot set backlink = '''' where slotname = myname; 781 end if; 782 return 0; 783 end if; 784 if mytype = ''PL'' then 785 select into rec * from PLine where slotname = myname; 786 if not found then 787 return 0; 788 end if; 789 if rec.backlink = blname then 790 update PLine set backlink = '''' where slotname = myname; 791 end if; 792 return 0; 793 end if; 794end 795' language plpgsql; 796 797 798-- ************************************************************ 799-- * AFTER INSERT or UPDATE or DELETE on slot with slotlink 800-- * - Ensure that the opponent correctly points back to us 801-- ************************************************************ 802create function tg_slotlink_a() returns trigger as ' 803declare 804 dummy integer; 805begin 806 if tg_op = ''INSERT'' then 807 if new.slotlink != '''' then 808 dummy := tg_slotlink_set(new.slotlink, new.slotname); 809 end if; 810 return new; 811 end if; 812 if tg_op = ''UPDATE'' then 813 if new.slotlink != old.slotlink then 814 if old.slotlink != '''' then 815 dummy := tg_slotlink_unset(old.slotlink, old.slotname); 816 end if; 817 if new.slotlink != '''' then 818 dummy := tg_slotlink_set(new.slotlink, new.slotname); 819 end if; 820 else 821 if new.slotname != old.slotname and new.slotlink != '''' then 822 dummy := tg_slotlink_set(new.slotlink, new.slotname); 823 end if; 824 end if; 825 return new; 826 end if; 827 if tg_op = ''DELETE'' then 828 if old.slotlink != '''' then 829 dummy := tg_slotlink_unset(old.slotlink, old.slotname); 830 end if; 831 return old; 832 end if; 833end; 834' language plpgsql; 835 836 837create trigger tg_slotlink_a after insert or update or delete 838 on PSlot for each row execute procedure tg_slotlink_a('PS'); 839 840create trigger tg_slotlink_a after insert or update or delete 841 on WSlot for each row execute procedure tg_slotlink_a('WS'); 842 843create trigger tg_slotlink_a after insert or update or delete 844 on IFace for each row execute procedure tg_slotlink_a('IF'); 845 846create trigger tg_slotlink_a after insert or update or delete 847 on HSlot for each row execute procedure tg_slotlink_a('HS'); 848 849create trigger tg_slotlink_a after insert or update or delete 850 on PHone for each row execute procedure tg_slotlink_a('PH'); 851 852 853-- ************************************************************ 854-- * Support function to set the opponents slotlink field 855-- * if it does not already point to the requested slot 856-- ************************************************************ 857create function tg_slotlink_set(bpchar, bpchar) 858returns integer as ' 859declare 860 myname alias for $1; 861 blname alias for $2; 862 mytype char(2); 863 link char(4); 864 rec record; 865begin 866 mytype := substr(myname, 1, 2); 867 link := mytype || substr(blname, 1, 2); 868 if link = ''PHPH'' then 869 raise exception 870 ''slotlink between two phones does not make sense''; 871 end if; 872 if link in (''PHHS'', ''HSPH'') then 873 raise exception 874 ''link of phone to hub does not make sense''; 875 end if; 876 if link in (''PHIF'', ''IFPH'') then 877 raise exception 878 ''link of phone to hub does not make sense''; 879 end if; 880 if link in (''PSWS'', ''WSPS'') then 881 raise exception 882 ''slotlink from patchslot to wallslot not permitted''; 883 end if; 884 if mytype = ''PS'' then 885 select into rec * from PSlot where slotname = myname; 886 if not found then 887 raise exception ''% does not exist'', myname; 888 end if; 889 if rec.slotlink != blname then 890 update PSlot set slotlink = blname where slotname = myname; 891 end if; 892 return 0; 893 end if; 894 if mytype = ''WS'' then 895 select into rec * from WSlot where slotname = myname; 896 if not found then 897 raise exception ''% does not exist'', myname; 898 end if; 899 if rec.slotlink != blname then 900 update WSlot set slotlink = blname where slotname = myname; 901 end if; 902 return 0; 903 end if; 904 if mytype = ''IF'' then 905 select into rec * from IFace where slotname = myname; 906 if not found then 907 raise exception ''% does not exist'', myname; 908 end if; 909 if rec.slotlink != blname then 910 update IFace set slotlink = blname where slotname = myname; 911 end if; 912 return 0; 913 end if; 914 if mytype = ''HS'' then 915 select into rec * from HSlot where slotname = myname; 916 if not found then 917 raise exception ''% does not exist'', myname; 918 end if; 919 if rec.slotlink != blname then 920 update HSlot set slotlink = blname where slotname = myname; 921 end if; 922 return 0; 923 end if; 924 if mytype = ''PH'' then 925 select into rec * from PHone where slotname = myname; 926 if not found then 927 raise exception ''% does not exist'', myname; 928 end if; 929 if rec.slotlink != blname then 930 update PHone set slotlink = blname where slotname = myname; 931 end if; 932 return 0; 933 end if; 934 raise exception ''illegal slotlink beginning with %'', mytype; 935end; 936' language plpgsql; 937 938 939-- ************************************************************ 940-- * Support function to clear out the slotlink field if 941-- * it still points to specific slot 942-- ************************************************************ 943create function tg_slotlink_unset(bpchar, bpchar) 944returns integer as ' 945declare 946 myname alias for $1; 947 blname alias for $2; 948 mytype char(2); 949 rec record; 950begin 951 mytype := substr(myname, 1, 2); 952 if mytype = ''PS'' then 953 select into rec * from PSlot where slotname = myname; 954 if not found then 955 return 0; 956 end if; 957 if rec.slotlink = blname then 958 update PSlot set slotlink = '''' where slotname = myname; 959 end if; 960 return 0; 961 end if; 962 if mytype = ''WS'' then 963 select into rec * from WSlot where slotname = myname; 964 if not found then 965 return 0; 966 end if; 967 if rec.slotlink = blname then 968 update WSlot set slotlink = '''' where slotname = myname; 969 end if; 970 return 0; 971 end if; 972 if mytype = ''IF'' then 973 select into rec * from IFace where slotname = myname; 974 if not found then 975 return 0; 976 end if; 977 if rec.slotlink = blname then 978 update IFace set slotlink = '''' where slotname = myname; 979 end if; 980 return 0; 981 end if; 982 if mytype = ''HS'' then 983 select into rec * from HSlot where slotname = myname; 984 if not found then 985 return 0; 986 end if; 987 if rec.slotlink = blname then 988 update HSlot set slotlink = '''' where slotname = myname; 989 end if; 990 return 0; 991 end if; 992 if mytype = ''PH'' then 993 select into rec * from PHone where slotname = myname; 994 if not found then 995 return 0; 996 end if; 997 if rec.slotlink = blname then 998 update PHone set slotlink = '''' where slotname = myname; 999 end if; 1000 return 0; 1001 end if; 1002end; 1003' language plpgsql; 1004 1005 1006-- ************************************************************ 1007-- * Describe the backside of a patchfield slot 1008-- ************************************************************ 1009create function pslot_backlink_view(bpchar) 1010returns text as ' 1011<<outer>> 1012declare 1013 rec record; 1014 bltype char(2); 1015 retval text; 1016begin 1017 select into rec * from PSlot where slotname = $1; 1018 if not found then 1019 return ''''; 1020 end if; 1021 if rec.backlink = '''' then 1022 return ''-''; 1023 end if; 1024 bltype := substr(rec.backlink, 1, 2); 1025 if bltype = ''PL'' then 1026 declare 1027 rec record; 1028 begin 1029 select into rec * from PLine where slotname = "outer".rec.backlink; 1030 retval := ''Phone line '' || trim(rec.phonenumber); 1031 if rec.comment != '''' then 1032 retval := retval || '' (''; 1033 retval := retval || rec.comment; 1034 retval := retval || '')''; 1035 end if; 1036 return retval; 1037 end; 1038 end if; 1039 if bltype = ''WS'' then 1040 select into rec * from WSlot where slotname = rec.backlink; 1041 retval := trim(rec.slotname) || '' in room ''; 1042 retval := retval || trim(rec.roomno); 1043 retval := retval || '' -> ''; 1044 return retval || wslot_slotlink_view(rec.slotname); 1045 end if; 1046 return rec.backlink; 1047end; 1048' language plpgsql; 1049 1050 1051-- ************************************************************ 1052-- * Describe the front of a patchfield slot 1053-- ************************************************************ 1054create function pslot_slotlink_view(bpchar) 1055returns text as ' 1056declare 1057 psrec record; 1058 sltype char(2); 1059 retval text; 1060begin 1061 select into psrec * from PSlot where slotname = $1; 1062 if not found then 1063 return ''''; 1064 end if; 1065 if psrec.slotlink = '''' then 1066 return ''-''; 1067 end if; 1068 sltype := substr(psrec.slotlink, 1, 2); 1069 if sltype = ''PS'' then 1070 retval := trim(psrec.slotlink) || '' -> ''; 1071 return retval || pslot_backlink_view(psrec.slotlink); 1072 end if; 1073 if sltype = ''HS'' then 1074 retval := comment from Hub H, HSlot HS 1075 where HS.slotname = psrec.slotlink 1076 and H.name = HS.hubname; 1077 retval := retval || '' slot ''; 1078 retval := retval || slotno::text from HSlot 1079 where slotname = psrec.slotlink; 1080 return retval; 1081 end if; 1082 return psrec.slotlink; 1083end; 1084' language plpgsql; 1085 1086 1087-- ************************************************************ 1088-- * Describe the front of a wall connector slot 1089-- ************************************************************ 1090create function wslot_slotlink_view(bpchar) 1091returns text as ' 1092declare 1093 rec record; 1094 sltype char(2); 1095 retval text; 1096begin 1097 select into rec * from WSlot where slotname = $1; 1098 if not found then 1099 return ''''; 1100 end if; 1101 if rec.slotlink = '''' then 1102 return ''-''; 1103 end if; 1104 sltype := substr(rec.slotlink, 1, 2); 1105 if sltype = ''PH'' then 1106 select into rec * from PHone where slotname = rec.slotlink; 1107 retval := ''Phone '' || trim(rec.slotname); 1108 if rec.comment != '''' then 1109 retval := retval || '' (''; 1110 retval := retval || rec.comment; 1111 retval := retval || '')''; 1112 end if; 1113 return retval; 1114 end if; 1115 if sltype = ''IF'' then 1116 declare 1117 syrow System%RowType; 1118 ifrow IFace%ROWTYPE; 1119 begin 1120 select into ifrow * from IFace where slotname = rec.slotlink; 1121 select into syrow * from System where name = ifrow.sysname; 1122 retval := syrow.name || '' IF ''; 1123 retval := retval || ifrow.ifname; 1124 if syrow.comment != '''' then 1125 retval := retval || '' (''; 1126 retval := retval || syrow.comment; 1127 retval := retval || '')''; 1128 end if; 1129 return retval; 1130 end; 1131 end if; 1132 return rec.slotlink; 1133end; 1134' language plpgsql; 1135 1136 1137 1138-- ************************************************************ 1139-- * View of a patchfield describing backside and patches 1140-- ************************************************************ 1141create view Pfield_v1 as select PF.pfname, PF.slotname, 1142 pslot_backlink_view(PF.slotname) as backside, 1143 pslot_slotlink_view(PF.slotname) as patch 1144 from PSlot PF; 1145 1146 1147-- 1148-- First we build the house - so we create the rooms 1149-- 1150insert into Room values ('001', 'Entrance'); 1151insert into Room values ('002', 'Office'); 1152insert into Room values ('003', 'Office'); 1153insert into Room values ('004', 'Technical'); 1154insert into Room values ('101', 'Office'); 1155insert into Room values ('102', 'Conference'); 1156insert into Room values ('103', 'Restroom'); 1157insert into Room values ('104', 'Technical'); 1158insert into Room values ('105', 'Office'); 1159insert into Room values ('106', 'Office'); 1160 1161-- 1162-- Second we install the wall connectors 1163-- 1164insert into WSlot values ('WS.001.1a', '001', '', ''); 1165insert into WSlot values ('WS.001.1b', '001', '', ''); 1166insert into WSlot values ('WS.001.2a', '001', '', ''); 1167insert into WSlot values ('WS.001.2b', '001', '', ''); 1168insert into WSlot values ('WS.001.3a', '001', '', ''); 1169insert into WSlot values ('WS.001.3b', '001', '', ''); 1170 1171insert into WSlot values ('WS.002.1a', '002', '', ''); 1172insert into WSlot values ('WS.002.1b', '002', '', ''); 1173insert into WSlot values ('WS.002.2a', '002', '', ''); 1174insert into WSlot values ('WS.002.2b', '002', '', ''); 1175insert into WSlot values ('WS.002.3a', '002', '', ''); 1176insert into WSlot values ('WS.002.3b', '002', '', ''); 1177 1178insert into WSlot values ('WS.003.1a', '003', '', ''); 1179insert into WSlot values ('WS.003.1b', '003', '', ''); 1180insert into WSlot values ('WS.003.2a', '003', '', ''); 1181insert into WSlot values ('WS.003.2b', '003', '', ''); 1182insert into WSlot values ('WS.003.3a', '003', '', ''); 1183insert into WSlot values ('WS.003.3b', '003', '', ''); 1184 1185insert into WSlot values ('WS.101.1a', '101', '', ''); 1186insert into WSlot values ('WS.101.1b', '101', '', ''); 1187insert into WSlot values ('WS.101.2a', '101', '', ''); 1188insert into WSlot values ('WS.101.2b', '101', '', ''); 1189insert into WSlot values ('WS.101.3a', '101', '', ''); 1190insert into WSlot values ('WS.101.3b', '101', '', ''); 1191 1192insert into WSlot values ('WS.102.1a', '102', '', ''); 1193insert into WSlot values ('WS.102.1b', '102', '', ''); 1194insert into WSlot values ('WS.102.2a', '102', '', ''); 1195insert into WSlot values ('WS.102.2b', '102', '', ''); 1196insert into WSlot values ('WS.102.3a', '102', '', ''); 1197insert into WSlot values ('WS.102.3b', '102', '', ''); 1198 1199insert into WSlot values ('WS.105.1a', '105', '', ''); 1200insert into WSlot values ('WS.105.1b', '105', '', ''); 1201insert into WSlot values ('WS.105.2a', '105', '', ''); 1202insert into WSlot values ('WS.105.2b', '105', '', ''); 1203insert into WSlot values ('WS.105.3a', '105', '', ''); 1204insert into WSlot values ('WS.105.3b', '105', '', ''); 1205 1206insert into WSlot values ('WS.106.1a', '106', '', ''); 1207insert into WSlot values ('WS.106.1b', '106', '', ''); 1208insert into WSlot values ('WS.106.2a', '106', '', ''); 1209insert into WSlot values ('WS.106.2b', '106', '', ''); 1210insert into WSlot values ('WS.106.3a', '106', '', ''); 1211insert into WSlot values ('WS.106.3b', '106', '', ''); 1212 1213-- 1214-- Now create the patch fields and their slots 1215-- 1216insert into PField values ('PF0_1', 'Wallslots basement'); 1217 1218-- 1219-- The cables for these will be made later, so they are unconnected for now 1220-- 1221insert into PSlot values ('PS.base.a1', 'PF0_1', '', ''); 1222insert into PSlot values ('PS.base.a2', 'PF0_1', '', ''); 1223insert into PSlot values ('PS.base.a3', 'PF0_1', '', ''); 1224insert into PSlot values ('PS.base.a4', 'PF0_1', '', ''); 1225insert into PSlot values ('PS.base.a5', 'PF0_1', '', ''); 1226insert into PSlot values ('PS.base.a6', 'PF0_1', '', ''); 1227 1228-- 1229-- These are already wired to the wall connectors 1230-- 1231insert into PSlot values ('PS.base.b1', 'PF0_1', '', 'WS.002.1a'); 1232insert into PSlot values ('PS.base.b2', 'PF0_1', '', 'WS.002.1b'); 1233insert into PSlot values ('PS.base.b3', 'PF0_1', '', 'WS.002.2a'); 1234insert into PSlot values ('PS.base.b4', 'PF0_1', '', 'WS.002.2b'); 1235insert into PSlot values ('PS.base.b5', 'PF0_1', '', 'WS.002.3a'); 1236insert into PSlot values ('PS.base.b6', 'PF0_1', '', 'WS.002.3b'); 1237 1238insert into PSlot values ('PS.base.c1', 'PF0_1', '', 'WS.003.1a'); 1239insert into PSlot values ('PS.base.c2', 'PF0_1', '', 'WS.003.1b'); 1240insert into PSlot values ('PS.base.c3', 'PF0_1', '', 'WS.003.2a'); 1241insert into PSlot values ('PS.base.c4', 'PF0_1', '', 'WS.003.2b'); 1242insert into PSlot values ('PS.base.c5', 'PF0_1', '', 'WS.003.3a'); 1243insert into PSlot values ('PS.base.c6', 'PF0_1', '', 'WS.003.3b'); 1244 1245-- 1246-- This patchfield will be renamed later into PF0_2 - so its 1247-- slots references in pfname should follow 1248-- 1249insert into PField values ('PF0_X', 'Phonelines basement'); 1250 1251insert into PSlot values ('PS.base.ta1', 'PF0_X', '', ''); 1252insert into PSlot values ('PS.base.ta2', 'PF0_X', '', ''); 1253insert into PSlot values ('PS.base.ta3', 'PF0_X', '', ''); 1254insert into PSlot values ('PS.base.ta4', 'PF0_X', '', ''); 1255insert into PSlot values ('PS.base.ta5', 'PF0_X', '', ''); 1256insert into PSlot values ('PS.base.ta6', 'PF0_X', '', ''); 1257 1258insert into PSlot values ('PS.base.tb1', 'PF0_X', '', ''); 1259insert into PSlot values ('PS.base.tb2', 'PF0_X', '', ''); 1260insert into PSlot values ('PS.base.tb3', 'PF0_X', '', ''); 1261insert into PSlot values ('PS.base.tb4', 'PF0_X', '', ''); 1262insert into PSlot values ('PS.base.tb5', 'PF0_X', '', ''); 1263insert into PSlot values ('PS.base.tb6', 'PF0_X', '', ''); 1264 1265insert into PField values ('PF1_1', 'Wallslots first floor'); 1266 1267insert into PSlot values ('PS.first.a1', 'PF1_1', '', 'WS.101.1a'); 1268insert into PSlot values ('PS.first.a2', 'PF1_1', '', 'WS.101.1b'); 1269insert into PSlot values ('PS.first.a3', 'PF1_1', '', 'WS.101.2a'); 1270insert into PSlot values ('PS.first.a4', 'PF1_1', '', 'WS.101.2b'); 1271insert into PSlot values ('PS.first.a5', 'PF1_1', '', 'WS.101.3a'); 1272insert into PSlot values ('PS.first.a6', 'PF1_1', '', 'WS.101.3b'); 1273 1274insert into PSlot values ('PS.first.b1', 'PF1_1', '', 'WS.102.1a'); 1275insert into PSlot values ('PS.first.b2', 'PF1_1', '', 'WS.102.1b'); 1276insert into PSlot values ('PS.first.b3', 'PF1_1', '', 'WS.102.2a'); 1277insert into PSlot values ('PS.first.b4', 'PF1_1', '', 'WS.102.2b'); 1278insert into PSlot values ('PS.first.b5', 'PF1_1', '', 'WS.102.3a'); 1279insert into PSlot values ('PS.first.b6', 'PF1_1', '', 'WS.102.3b'); 1280 1281insert into PSlot values ('PS.first.c1', 'PF1_1', '', 'WS.105.1a'); 1282insert into PSlot values ('PS.first.c2', 'PF1_1', '', 'WS.105.1b'); 1283insert into PSlot values ('PS.first.c3', 'PF1_1', '', 'WS.105.2a'); 1284insert into PSlot values ('PS.first.c4', 'PF1_1', '', 'WS.105.2b'); 1285insert into PSlot values ('PS.first.c5', 'PF1_1', '', 'WS.105.3a'); 1286insert into PSlot values ('PS.first.c6', 'PF1_1', '', 'WS.105.3b'); 1287 1288insert into PSlot values ('PS.first.d1', 'PF1_1', '', 'WS.106.1a'); 1289insert into PSlot values ('PS.first.d2', 'PF1_1', '', 'WS.106.1b'); 1290insert into PSlot values ('PS.first.d3', 'PF1_1', '', 'WS.106.2a'); 1291insert into PSlot values ('PS.first.d4', 'PF1_1', '', 'WS.106.2b'); 1292insert into PSlot values ('PS.first.d5', 'PF1_1', '', 'WS.106.3a'); 1293insert into PSlot values ('PS.first.d6', 'PF1_1', '', 'WS.106.3b'); 1294 1295-- 1296-- Now we wire the wall connectors 1a-2a in room 001 to the 1297-- patchfield. In the second update we make an error, and 1298-- correct it after 1299-- 1300update PSlot set backlink = 'WS.001.1a' where slotname = 'PS.base.a1'; 1301update PSlot set backlink = 'WS.001.1b' where slotname = 'PS.base.a3'; 1302select * from WSlot where roomno = '001' order by slotname; 1303select * from PSlot where slotname ~ 'PS.base.a' order by slotname; 1304update PSlot set backlink = 'WS.001.2a' where slotname = 'PS.base.a3'; 1305select * from WSlot where roomno = '001' order by slotname; 1306select * from PSlot where slotname ~ 'PS.base.a' order by slotname; 1307update PSlot set backlink = 'WS.001.1b' where slotname = 'PS.base.a2'; 1308select * from WSlot where roomno = '001' order by slotname; 1309select * from PSlot where slotname ~ 'PS.base.a' order by slotname; 1310 1311-- 1312-- Same procedure for 2b-3b but this time updating the WSlot instead 1313-- of the PSlot. Due to the triggers the result is the same: 1314-- WSlot and corresponding PSlot point to each other. 1315-- 1316update WSlot set backlink = 'PS.base.a4' where slotname = 'WS.001.2b'; 1317update WSlot set backlink = 'PS.base.a6' where slotname = 'WS.001.3a'; 1318select * from WSlot where roomno = '001' order by slotname; 1319select * from PSlot where slotname ~ 'PS.base.a' order by slotname; 1320update WSlot set backlink = 'PS.base.a6' where slotname = 'WS.001.3b'; 1321select * from WSlot where roomno = '001' order by slotname; 1322select * from PSlot where slotname ~ 'PS.base.a' order by slotname; 1323update WSlot set backlink = 'PS.base.a5' where slotname = 'WS.001.3a'; 1324select * from WSlot where roomno = '001' order by slotname; 1325select * from PSlot where slotname ~ 'PS.base.a' order by slotname; 1326 1327insert into PField values ('PF1_2', 'Phonelines first floor'); 1328 1329insert into PSlot values ('PS.first.ta1', 'PF1_2', '', ''); 1330insert into PSlot values ('PS.first.ta2', 'PF1_2', '', ''); 1331insert into PSlot values ('PS.first.ta3', 'PF1_2', '', ''); 1332insert into PSlot values ('PS.first.ta4', 'PF1_2', '', ''); 1333insert into PSlot values ('PS.first.ta5', 'PF1_2', '', ''); 1334insert into PSlot values ('PS.first.ta6', 'PF1_2', '', ''); 1335 1336insert into PSlot values ('PS.first.tb1', 'PF1_2', '', ''); 1337insert into PSlot values ('PS.first.tb2', 'PF1_2', '', ''); 1338insert into PSlot values ('PS.first.tb3', 'PF1_2', '', ''); 1339insert into PSlot values ('PS.first.tb4', 'PF1_2', '', ''); 1340insert into PSlot values ('PS.first.tb5', 'PF1_2', '', ''); 1341insert into PSlot values ('PS.first.tb6', 'PF1_2', '', ''); 1342 1343-- 1344-- Fix the wrong name for patchfield PF0_2 1345-- 1346update PField set name = 'PF0_2' where name = 'PF0_X'; 1347 1348select * from PSlot order by slotname; 1349select * from WSlot order by slotname; 1350 1351-- 1352-- Install the central phone system and create the phone numbers. 1353-- They are wired on insert to the patchfields. Again the 1354-- triggers automatically tell the PSlots to update their 1355-- backlink field. 1356-- 1357insert into PLine values ('PL.001', '-0', 'Central call', 'PS.base.ta1'); 1358insert into PLine values ('PL.002', '-101', '', 'PS.base.ta2'); 1359insert into PLine values ('PL.003', '-102', '', 'PS.base.ta3'); 1360insert into PLine values ('PL.004', '-103', '', 'PS.base.ta5'); 1361insert into PLine values ('PL.005', '-104', '', 'PS.base.ta6'); 1362insert into PLine values ('PL.006', '-106', '', 'PS.base.tb2'); 1363insert into PLine values ('PL.007', '-108', '', 'PS.base.tb3'); 1364insert into PLine values ('PL.008', '-109', '', 'PS.base.tb4'); 1365insert into PLine values ('PL.009', '-121', '', 'PS.base.tb5'); 1366insert into PLine values ('PL.010', '-122', '', 'PS.base.tb6'); 1367insert into PLine values ('PL.015', '-134', '', 'PS.first.ta1'); 1368insert into PLine values ('PL.016', '-137', '', 'PS.first.ta3'); 1369insert into PLine values ('PL.017', '-139', '', 'PS.first.ta4'); 1370insert into PLine values ('PL.018', '-362', '', 'PS.first.tb1'); 1371insert into PLine values ('PL.019', '-363', '', 'PS.first.tb2'); 1372insert into PLine values ('PL.020', '-364', '', 'PS.first.tb3'); 1373insert into PLine values ('PL.021', '-365', '', 'PS.first.tb5'); 1374insert into PLine values ('PL.022', '-367', '', 'PS.first.tb6'); 1375insert into PLine values ('PL.028', '-501', 'Fax entrance', 'PS.base.ta2'); 1376insert into PLine values ('PL.029', '-502', 'Fax first floor', 'PS.first.ta1'); 1377 1378-- 1379-- Buy some phones, plug them into the wall and patch the 1380-- phone lines to the corresponding patchfield slots. 1381-- 1382insert into PHone values ('PH.hc001', 'Hicom standard', 'WS.001.1a'); 1383update PSlot set slotlink = 'PS.base.ta1' where slotname = 'PS.base.a1'; 1384insert into PHone values ('PH.hc002', 'Hicom standard', 'WS.002.1a'); 1385update PSlot set slotlink = 'PS.base.ta5' where slotname = 'PS.base.b1'; 1386insert into PHone values ('PH.hc003', 'Hicom standard', 'WS.002.2a'); 1387update PSlot set slotlink = 'PS.base.tb2' where slotname = 'PS.base.b3'; 1388insert into PHone values ('PH.fax001', 'Canon fax', 'WS.001.2a'); 1389update PSlot set slotlink = 'PS.base.ta2' where slotname = 'PS.base.a3'; 1390 1391-- 1392-- Install a hub at one of the patchfields, plug a computers 1393-- ethernet interface into the wall and patch it to the hub. 1394-- 1395insert into Hub values ('base.hub1', 'Patchfield PF0_1 hub', 16); 1396insert into System values ('orion', 'PC'); 1397insert into IFace values ('IF', 'orion', 'eth0', 'WS.002.1b'); 1398update PSlot set slotlink = 'HS.base.hub1.1' where slotname = 'PS.base.b2'; 1399 1400-- 1401-- Now we take a look at the patchfield 1402-- 1403select * from PField_v1 where pfname = 'PF0_1' order by slotname; 1404select * from PField_v1 where pfname = 'PF0_2' order by slotname; 1405 1406-- 1407-- Finally we want errors 1408-- 1409insert into PField values ('PF1_1', 'should fail due to unique index'); 1410update PSlot set backlink = 'WS.not.there' where slotname = 'PS.base.a1'; 1411update PSlot set backlink = 'XX.illegal' where slotname = 'PS.base.a1'; 1412update PSlot set slotlink = 'PS.not.there' where slotname = 'PS.base.a1'; 1413update PSlot set slotlink = 'XX.illegal' where slotname = 'PS.base.a1'; 1414insert into HSlot values ('HS', 'base.hub1', 1, ''); 1415insert into HSlot values ('HS', 'base.hub1', 20, ''); 1416delete from HSlot; 1417insert into IFace values ('IF', 'notthere', 'eth0', ''); 1418insert into IFace values ('IF', 'orion', 'ethernet_interface_name_too_long', ''); 1419 1420 1421-- 1422-- The following tests are unrelated to the scenario outlined above; 1423-- they merely exercise specific parts of PL/pgSQL 1424-- 1425 1426-- 1427-- Test recursion, per bug report 7-Sep-01 1428-- 1429CREATE FUNCTION recursion_test(int,int) RETURNS text AS ' 1430DECLARE rslt text; 1431BEGIN 1432 IF $1 <= 0 THEN 1433 rslt = CAST($2 AS TEXT); 1434 ELSE 1435 rslt = CAST($1 AS TEXT) || '','' || recursion_test($1 - 1, $2); 1436 END IF; 1437 RETURN rslt; 1438END;' LANGUAGE plpgsql; 1439 1440SELECT recursion_test(4,3); 1441 1442-- 1443-- Test the FOUND magic variable 1444-- 1445CREATE TABLE found_test_tbl (a int); 1446 1447create function test_found() 1448 returns boolean as ' 1449 declare 1450 begin 1451 insert into found_test_tbl values (1); 1452 if FOUND then 1453 insert into found_test_tbl values (2); 1454 end if; 1455 1456 update found_test_tbl set a = 100 where a = 1; 1457 if FOUND then 1458 insert into found_test_tbl values (3); 1459 end if; 1460 1461 delete from found_test_tbl where a = 9999; -- matches no rows 1462 if not FOUND then 1463 insert into found_test_tbl values (4); 1464 end if; 1465 1466 for i in 1 .. 10 loop 1467 -- no need to do anything 1468 end loop; 1469 if FOUND then 1470 insert into found_test_tbl values (5); 1471 end if; 1472 1473 -- never executes the loop 1474 for i in 2 .. 1 loop 1475 -- no need to do anything 1476 end loop; 1477 if not FOUND then 1478 insert into found_test_tbl values (6); 1479 end if; 1480 return true; 1481 end;' language plpgsql; 1482 1483select test_found(); 1484select * from found_test_tbl; 1485 1486-- 1487-- Test set-returning functions for PL/pgSQL 1488-- 1489 1490create function test_table_func_rec() returns setof found_test_tbl as ' 1491DECLARE 1492 rec RECORD; 1493BEGIN 1494 FOR rec IN select * from found_test_tbl LOOP 1495 RETURN NEXT rec; 1496 END LOOP; 1497 RETURN; 1498END;' language plpgsql; 1499 1500select * from test_table_func_rec(); 1501 1502create function test_table_func_row() returns setof found_test_tbl as ' 1503DECLARE 1504 row found_test_tbl%ROWTYPE; 1505BEGIN 1506 FOR row IN select * from found_test_tbl LOOP 1507 RETURN NEXT row; 1508 END LOOP; 1509 RETURN; 1510END;' language plpgsql; 1511 1512select * from test_table_func_row(); 1513 1514create function test_ret_set_scalar(int,int) returns setof int as ' 1515DECLARE 1516 i int; 1517BEGIN 1518 FOR i IN $1 .. $2 LOOP 1519 RETURN NEXT i + 1; 1520 END LOOP; 1521 RETURN; 1522END;' language plpgsql; 1523 1524select * from test_ret_set_scalar(1,10); 1525 1526create function test_ret_set_rec_dyn(int) returns setof record as ' 1527DECLARE 1528 retval RECORD; 1529BEGIN 1530 IF $1 > 10 THEN 1531 SELECT INTO retval 5, 10, 15; 1532 RETURN NEXT retval; 1533 RETURN NEXT retval; 1534 ELSE 1535 SELECT INTO retval 50, 5::numeric, ''xxx''::text; 1536 RETURN NEXT retval; 1537 RETURN NEXT retval; 1538 END IF; 1539 RETURN; 1540END;' language plpgsql; 1541 1542SELECT * FROM test_ret_set_rec_dyn(1500) AS (a int, b int, c int); 1543SELECT * FROM test_ret_set_rec_dyn(5) AS (a int, b numeric, c text); 1544 1545create function test_ret_rec_dyn(int) returns record as ' 1546DECLARE 1547 retval RECORD; 1548BEGIN 1549 IF $1 > 10 THEN 1550 SELECT INTO retval 5, 10, 15; 1551 RETURN retval; 1552 ELSE 1553 SELECT INTO retval 50, 5::numeric, ''xxx''::text; 1554 RETURN retval; 1555 END IF; 1556END;' language plpgsql; 1557 1558SELECT * FROM test_ret_rec_dyn(1500) AS (a int, b int, c int); 1559SELECT * FROM test_ret_rec_dyn(5) AS (a int, b numeric, c text); 1560 1561-- 1562-- Test handling of OUT parameters, including polymorphic cases. 1563-- Note that RETURN is optional with OUT params; we try both ways. 1564-- 1565 1566-- wrong way to do it: 1567create function f1(in i int, out j int) returns int as $$ 1568begin 1569 return i+1; 1570end$$ language plpgsql; 1571 1572create function f1(in i int, out j int) as $$ 1573begin 1574 j := i+1; 1575 return; 1576end$$ language plpgsql; 1577 1578select f1(42); 1579select * from f1(42); 1580 1581create or replace function f1(inout i int) as $$ 1582begin 1583 i := i+1; 1584end$$ language plpgsql; 1585 1586select f1(42); 1587select * from f1(42); 1588 1589drop function f1(int); 1590 1591create function f1(in i int, out j int) returns setof int as $$ 1592begin 1593 j := i+1; 1594 return next; 1595 j := i+2; 1596 return next; 1597 return; 1598end$$ language plpgsql; 1599 1600select * from f1(42); 1601 1602drop function f1(int); 1603 1604create function f1(in i int, out j int, out k text) as $$ 1605begin 1606 j := i; 1607 j := j+1; 1608 k := 'foo'; 1609end$$ language plpgsql; 1610 1611select f1(42); 1612select * from f1(42); 1613 1614drop function f1(int); 1615 1616create function f1(in i int, out j int, out k text) returns setof record as $$ 1617begin 1618 j := i+1; 1619 k := 'foo'; 1620 return next; 1621 j := j+1; 1622 k := 'foot'; 1623 return next; 1624end$$ language plpgsql; 1625 1626select * from f1(42); 1627 1628drop function f1(int); 1629 1630create function duplic(in i anyelement, out j anyelement, out k anyarray) as $$ 1631begin 1632 j := i; 1633 k := array[j,j]; 1634 return; 1635end$$ language plpgsql; 1636 1637select * from duplic(42); 1638select * from duplic('foo'::text); 1639 1640drop function duplic(anyelement); 1641 1642-- 1643-- test PERFORM 1644-- 1645 1646create table perform_test ( 1647 a INT, 1648 b INT 1649); 1650 1651create function perform_simple_func(int) returns boolean as ' 1652BEGIN 1653 IF $1 < 20 THEN 1654 INSERT INTO perform_test VALUES ($1, $1 + 10); 1655 RETURN TRUE; 1656 ELSE 1657 RETURN FALSE; 1658 END IF; 1659END;' language plpgsql; 1660 1661create function perform_test_func() returns void as ' 1662BEGIN 1663 IF FOUND then 1664 INSERT INTO perform_test VALUES (100, 100); 1665 END IF; 1666 1667 PERFORM perform_simple_func(5); 1668 1669 IF FOUND then 1670 INSERT INTO perform_test VALUES (100, 100); 1671 END IF; 1672 1673 PERFORM perform_simple_func(50); 1674 1675 IF FOUND then 1676 INSERT INTO perform_test VALUES (100, 100); 1677 END IF; 1678 1679 RETURN; 1680END;' language plpgsql; 1681 1682SELECT perform_test_func(); 1683SELECT * FROM perform_test; 1684 1685drop table perform_test; 1686 1687-- 1688-- Test error trapping 1689-- 1690 1691create function trap_zero_divide(int) returns int as $$ 1692declare x int; 1693 sx smallint; 1694begin 1695 begin -- start a subtransaction 1696 raise notice 'should see this'; 1697 x := 100 / $1; 1698 raise notice 'should see this only if % <> 0', $1; 1699 sx := $1; 1700 raise notice 'should see this only if % fits in smallint', $1; 1701 if $1 < 0 then 1702 raise exception '% is less than zero', $1; 1703 end if; 1704 exception 1705 when division_by_zero then 1706 raise notice 'caught division_by_zero'; 1707 x := -1; 1708 when NUMERIC_VALUE_OUT_OF_RANGE then 1709 raise notice 'caught numeric_value_out_of_range'; 1710 x := -2; 1711 end; 1712 return x; 1713end$$ language plpgsql; 1714 1715select trap_zero_divide(50); 1716select trap_zero_divide(0); 1717select trap_zero_divide(100000); 1718select trap_zero_divide(-100); 1719 1720create function trap_matching_test(int) returns int as $$ 1721declare x int; 1722 sx smallint; 1723 y int; 1724begin 1725 begin -- start a subtransaction 1726 x := 100 / $1; 1727 sx := $1; 1728 select into y unique1 from tenk1 where unique2 = 1729 (select unique2 from tenk1 b where ten = $1); 1730 exception 1731 when data_exception then -- category match 1732 raise notice 'caught data_exception'; 1733 x := -1; 1734 when NUMERIC_VALUE_OUT_OF_RANGE OR CARDINALITY_VIOLATION then 1735 raise notice 'caught numeric_value_out_of_range or cardinality_violation'; 1736 x := -2; 1737 end; 1738 return x; 1739end$$ language plpgsql; 1740 1741select trap_matching_test(50); 1742select trap_matching_test(0); 1743select trap_matching_test(100000); 1744select trap_matching_test(1); 1745 1746create temp table foo (f1 int); 1747 1748create function subxact_rollback_semantics() returns int as $$ 1749declare x int; 1750begin 1751 x := 1; 1752 insert into foo values(x); 1753 begin 1754 x := x + 1; 1755 insert into foo values(x); 1756 raise exception 'inner'; 1757 exception 1758 when others then 1759 x := x * 10; 1760 end; 1761 insert into foo values(x); 1762 return x; 1763end$$ language plpgsql; 1764 1765select subxact_rollback_semantics(); 1766select * from foo; 1767drop table foo; 1768 1769create function trap_timeout() returns void as $$ 1770begin 1771 declare x int; 1772 begin 1773 -- we assume this will take longer than 2 seconds: 1774 select count(*) into x from tenk1 a, tenk1 b, tenk1 c; 1775 exception 1776 when others then 1777 raise notice 'caught others?'; 1778 when query_canceled then 1779 raise notice 'nyeah nyeah, can''t stop me'; 1780 end; 1781 -- Abort transaction to abandon the statement_timeout setting. Otherwise, 1782 -- the next top-level statement would be vulnerable to the timeout. 1783 raise exception 'end of function'; 1784end$$ language plpgsql; 1785 1786begin; 1787set statement_timeout to 2000; 1788select trap_timeout(); 1789rollback; 1790 1791-- Test for pass-by-ref values being stored in proper context 1792create function test_variable_storage() returns text as $$ 1793declare x text; 1794begin 1795 x := '1234'; 1796 begin 1797 x := x || '5678'; 1798 -- force error inside subtransaction SPI context 1799 perform trap_zero_divide(-100); 1800 exception 1801 when others then 1802 x := x || '9012'; 1803 end; 1804 return x; 1805end$$ language plpgsql; 1806 1807select test_variable_storage(); 1808 1809-- 1810-- test foreign key error trapping 1811-- 1812 1813create temp table master(f1 int primary key); 1814 1815create temp table slave(f1 int references master deferrable); 1816 1817insert into master values(1); 1818insert into slave values(1); 1819insert into slave values(2); -- fails 1820 1821create function trap_foreign_key(int) returns int as $$ 1822begin 1823 begin -- start a subtransaction 1824 insert into slave values($1); 1825 exception 1826 when foreign_key_violation then 1827 raise notice 'caught foreign_key_violation'; 1828 return 0; 1829 end; 1830 return 1; 1831end$$ language plpgsql; 1832 1833create function trap_foreign_key_2() returns int as $$ 1834begin 1835 begin -- start a subtransaction 1836 set constraints all immediate; 1837 exception 1838 when foreign_key_violation then 1839 raise notice 'caught foreign_key_violation'; 1840 return 0; 1841 end; 1842 return 1; 1843end$$ language plpgsql; 1844 1845select trap_foreign_key(1); 1846select trap_foreign_key(2); -- detects FK violation 1847 1848begin; 1849 set constraints all deferred; 1850 select trap_foreign_key(2); -- should not detect FK violation 1851 savepoint x; 1852 set constraints all immediate; -- fails 1853 rollback to x; 1854 select trap_foreign_key_2(); -- detects FK violation 1855commit; -- still fails 1856 1857drop function trap_foreign_key(int); 1858drop function trap_foreign_key_2(); 1859 1860-- 1861-- Test proper snapshot handling in simple expressions 1862-- 1863 1864create temp table users(login text, id serial); 1865 1866create function sp_id_user(a_login text) returns int as $$ 1867declare x int; 1868begin 1869 select into x id from users where login = a_login; 1870 if found then return x; end if; 1871 return 0; 1872end$$ language plpgsql stable; 1873 1874insert into users values('user1'); 1875 1876select sp_id_user('user1'); 1877select sp_id_user('userx'); 1878 1879create function sp_add_user(a_login text) returns int as $$ 1880declare my_id_user int; 1881begin 1882 my_id_user = sp_id_user( a_login ); 1883 IF my_id_user > 0 THEN 1884 RETURN -1; -- error code for existing user 1885 END IF; 1886 INSERT INTO users ( login ) VALUES ( a_login ); 1887 my_id_user = sp_id_user( a_login ); 1888 IF my_id_user = 0 THEN 1889 RETURN -2; -- error code for insertion failure 1890 END IF; 1891 RETURN my_id_user; 1892end$$ language plpgsql; 1893 1894select sp_add_user('user1'); 1895select sp_add_user('user2'); 1896select sp_add_user('user2'); 1897select sp_add_user('user3'); 1898select sp_add_user('user3'); 1899 1900drop function sp_add_user(text); 1901drop function sp_id_user(text); 1902 1903-- 1904-- tests for refcursors 1905-- 1906create table rc_test (a int, b int); 1907copy rc_test from stdin; 19085 10 190950 100 1910500 1000 1911\. 1912 1913create function return_unnamed_refcursor() returns refcursor as $$ 1914declare 1915 rc refcursor; 1916begin 1917 open rc for select a from rc_test; 1918 return rc; 1919end 1920$$ language plpgsql; 1921 1922create function use_refcursor(rc refcursor) returns int as $$ 1923declare 1924 rc refcursor; 1925 x record; 1926begin 1927 rc := return_unnamed_refcursor(); 1928 fetch next from rc into x; 1929 return x.a; 1930end 1931$$ language plpgsql; 1932 1933select use_refcursor(return_unnamed_refcursor()); 1934 1935create function return_refcursor(rc refcursor) returns refcursor as $$ 1936begin 1937 open rc for select a from rc_test; 1938 return rc; 1939end 1940$$ language plpgsql; 1941 1942create function refcursor_test1(refcursor) returns refcursor as $$ 1943begin 1944 perform return_refcursor($1); 1945 return $1; 1946end 1947$$ language plpgsql; 1948 1949begin; 1950 1951select refcursor_test1('test1'); 1952fetch next in test1; 1953 1954select refcursor_test1('test2'); 1955fetch all from test2; 1956 1957commit; 1958 1959-- should fail 1960fetch next from test1; 1961 1962create function refcursor_test2(int, int) returns boolean as $$ 1963declare 1964 c1 cursor (param1 int, param2 int) for select * from rc_test where a > param1 and b > param2; 1965 nonsense record; 1966begin 1967 open c1($1, $2); 1968 fetch c1 into nonsense; 1969 close c1; 1970 if found then 1971 return true; 1972 else 1973 return false; 1974 end if; 1975end 1976$$ language plpgsql; 1977 1978select refcursor_test2(20000, 20000) as "Should be false", 1979 refcursor_test2(20, 20) as "Should be true"; 1980 1981-- 1982-- tests for cursors with named parameter arguments 1983-- 1984create function namedparmcursor_test1(int, int) returns boolean as $$ 1985declare 1986 c1 cursor (param1 int, param12 int) for select * from rc_test where a > param1 and b > param12; 1987 nonsense record; 1988begin 1989 open c1(param12 := $2, param1 := $1); 1990 fetch c1 into nonsense; 1991 close c1; 1992 if found then 1993 return true; 1994 else 1995 return false; 1996 end if; 1997end 1998$$ language plpgsql; 1999 2000select namedparmcursor_test1(20000, 20000) as "Should be false", 2001 namedparmcursor_test1(20, 20) as "Should be true"; 2002 2003-- mixing named and positional argument notations 2004create function namedparmcursor_test2(int, int) returns boolean as $$ 2005declare 2006 c1 cursor (param1 int, param2 int) for select * from rc_test where a > param1 and b > param2; 2007 nonsense record; 2008begin 2009 open c1(param1 := $1, $2); 2010 fetch c1 into nonsense; 2011 close c1; 2012 if found then 2013 return true; 2014 else 2015 return false; 2016 end if; 2017end 2018$$ language plpgsql; 2019select namedparmcursor_test2(20, 20); 2020 2021-- mixing named and positional: param2 is given twice, once in named notation 2022-- and second time in positional notation. Should throw an error at parse time 2023create function namedparmcursor_test3() returns void as $$ 2024declare 2025 c1 cursor (param1 int, param2 int) for select * from rc_test where a > param1 and b > param2; 2026begin 2027 open c1(param2 := 20, 21); 2028end 2029$$ language plpgsql; 2030 2031-- mixing named and positional: same as previous test, but param1 is duplicated 2032create function namedparmcursor_test4() returns void as $$ 2033declare 2034 c1 cursor (param1 int, param2 int) for select * from rc_test where a > param1 and b > param2; 2035begin 2036 open c1(20, param1 := 21); 2037end 2038$$ language plpgsql; 2039 2040-- duplicate named parameter, should throw an error at parse time 2041create function namedparmcursor_test5() returns void as $$ 2042declare 2043 c1 cursor (p1 int, p2 int) for 2044 select * from tenk1 where thousand = p1 and tenthous = p2; 2045begin 2046 open c1 (p2 := 77, p2 := 42); 2047end 2048$$ language plpgsql; 2049 2050-- not enough parameters, should throw an error at parse time 2051create function namedparmcursor_test6() returns void as $$ 2052declare 2053 c1 cursor (p1 int, p2 int) for 2054 select * from tenk1 where thousand = p1 and tenthous = p2; 2055begin 2056 open c1 (p2 := 77); 2057end 2058$$ language plpgsql; 2059 2060-- division by zero runtime error, the context given in the error message 2061-- should be sensible 2062create function namedparmcursor_test7() returns void as $$ 2063declare 2064 c1 cursor (p1 int, p2 int) for 2065 select * from tenk1 where thousand = p1 and tenthous = p2; 2066begin 2067 open c1 (p2 := 77, p1 := 42/0); 2068end $$ language plpgsql; 2069select namedparmcursor_test7(); 2070 2071-- check that line comments work correctly within the argument list (there 2072-- is some special handling of this case in the code: the newline after the 2073-- comment must be preserved when the argument-evaluating query is 2074-- constructed, otherwise the comment effectively comments out the next 2075-- argument, too) 2076create function namedparmcursor_test8() returns int4 as $$ 2077declare 2078 c1 cursor (p1 int, p2 int) for 2079 select count(*) from tenk1 where thousand = p1 and tenthous = p2; 2080 n int4; 2081begin 2082 open c1 (77 -- test 2083 , 42); 2084 fetch c1 into n; 2085 return n; 2086end $$ language plpgsql; 2087select namedparmcursor_test8(); 2088 2089-- cursor parameter name can match plpgsql variable or unreserved keyword 2090create function namedparmcursor_test9(p1 int) returns int4 as $$ 2091declare 2092 c1 cursor (p1 int, p2 int, debug int) for 2093 select count(*) from tenk1 where thousand = p1 and tenthous = p2 2094 and four = debug; 2095 p2 int4 := 1006; 2096 n int4; 2097begin 2098 open c1 (p1 := p1, p2 := p2, debug := 2); 2099 fetch c1 into n; 2100 return n; 2101end $$ language plpgsql; 2102select namedparmcursor_test9(6); 2103 2104-- 2105-- tests for "raise" processing 2106-- 2107create function raise_test1(int) returns int as $$ 2108begin 2109 raise notice 'This message has too many parameters!', $1; 2110 return $1; 2111end; 2112$$ language plpgsql; 2113 2114create function raise_test2(int) returns int as $$ 2115begin 2116 raise notice 'This message has too few parameters: %, %, %', $1, $1; 2117 return $1; 2118end; 2119$$ language plpgsql; 2120 2121create function raise_test3(int) returns int as $$ 2122begin 2123 raise notice 'This message has no parameters (despite having %% signs in it)!'; 2124 return $1; 2125end; 2126$$ language plpgsql; 2127 2128select raise_test3(1); 2129 2130-- Test re-RAISE inside a nested exception block. This case is allowed 2131-- by Oracle's PL/SQL but was handled differently by PG before 9.1. 2132 2133CREATE FUNCTION reraise_test() RETURNS void AS $$ 2134BEGIN 2135 BEGIN 2136 RAISE syntax_error; 2137 EXCEPTION 2138 WHEN syntax_error THEN 2139 BEGIN 2140 raise notice 'exception % thrown in inner block, reraising', sqlerrm; 2141 RAISE; 2142 EXCEPTION 2143 WHEN OTHERS THEN 2144 raise notice 'RIGHT - exception % caught in inner block', sqlerrm; 2145 END; 2146 END; 2147EXCEPTION 2148 WHEN OTHERS THEN 2149 raise notice 'WRONG - exception % caught in outer block', sqlerrm; 2150END; 2151$$ LANGUAGE plpgsql; 2152 2153SELECT reraise_test(); 2154 2155-- 2156-- reject function definitions that contain malformed SQL queries at 2157-- compile-time, where possible 2158-- 2159create function bad_sql1() returns int as $$ 2160declare a int; 2161begin 2162 a := 5; 2163 Johnny Yuma; 2164 a := 10; 2165 return a; 2166end$$ language plpgsql; 2167 2168create function bad_sql2() returns int as $$ 2169declare r record; 2170begin 2171 for r in select I fought the law, the law won LOOP 2172 raise notice 'in loop'; 2173 end loop; 2174 return 5; 2175end;$$ language plpgsql; 2176 2177-- a RETURN expression is mandatory, except for void-returning 2178-- functions, where it is not allowed 2179create function missing_return_expr() returns int as $$ 2180begin 2181 return ; 2182end;$$ language plpgsql; 2183 2184create function void_return_expr() returns void as $$ 2185begin 2186 return 5; 2187end;$$ language plpgsql; 2188 2189-- VOID functions are allowed to omit RETURN 2190create function void_return_expr() returns void as $$ 2191begin 2192 perform 2+2; 2193end;$$ language plpgsql; 2194 2195select void_return_expr(); 2196 2197-- but ordinary functions are not 2198create function missing_return_expr() returns int as $$ 2199begin 2200 perform 2+2; 2201end;$$ language plpgsql; 2202 2203select missing_return_expr(); 2204 2205drop function void_return_expr(); 2206drop function missing_return_expr(); 2207 2208-- 2209-- EXECUTE ... INTO test 2210-- 2211 2212create table eifoo (i integer, y integer); 2213create type eitype as (i integer, y integer); 2214 2215create or replace function execute_into_test(varchar) returns record as $$ 2216declare 2217 _r record; 2218 _rt eifoo%rowtype; 2219 _v eitype; 2220 i int; 2221 j int; 2222 k int; 2223begin 2224 execute 'insert into '||$1||' values(10,15)'; 2225 execute 'select (row).* from (select row(10,1)::eifoo) s' into _r; 2226 raise notice '% %', _r.i, _r.y; 2227 execute 'select * from '||$1||' limit 1' into _rt; 2228 raise notice '% %', _rt.i, _rt.y; 2229 execute 'select *, 20 from '||$1||' limit 1' into i, j, k; 2230 raise notice '% % %', i, j, k; 2231 execute 'select 1,2' into _v; 2232 return _v; 2233end; $$ language plpgsql; 2234 2235select execute_into_test('eifoo'); 2236 2237drop table eifoo cascade; 2238drop type eitype cascade; 2239 2240-- 2241-- SQLSTATE and SQLERRM test 2242-- 2243 2244create function excpt_test1() returns void as $$ 2245begin 2246 raise notice '% %', sqlstate, sqlerrm; 2247end; $$ language plpgsql; 2248-- should fail: SQLSTATE and SQLERRM are only in defined EXCEPTION 2249-- blocks 2250select excpt_test1(); 2251 2252create function excpt_test2() returns void as $$ 2253begin 2254 begin 2255 begin 2256 raise notice '% %', sqlstate, sqlerrm; 2257 end; 2258 end; 2259end; $$ language plpgsql; 2260-- should fail 2261select excpt_test2(); 2262 2263create function excpt_test3() returns void as $$ 2264begin 2265 begin 2266 raise exception 'user exception'; 2267 exception when others then 2268 raise notice 'caught exception % %', sqlstate, sqlerrm; 2269 begin 2270 raise notice '% %', sqlstate, sqlerrm; 2271 perform 10/0; 2272 exception 2273 when substring_error then 2274 -- this exception handler shouldn't be invoked 2275 raise notice 'unexpected exception: % %', sqlstate, sqlerrm; 2276 when division_by_zero then 2277 raise notice 'caught exception % %', sqlstate, sqlerrm; 2278 end; 2279 raise notice '% %', sqlstate, sqlerrm; 2280 end; 2281end; $$ language plpgsql; 2282select excpt_test3(); 2283 2284create function excpt_test4() returns text as $$ 2285begin 2286 begin perform 1/0; 2287 exception when others then return sqlerrm; end; 2288end; $$ language plpgsql; 2289select excpt_test4(); 2290 2291drop function excpt_test1(); 2292drop function excpt_test2(); 2293drop function excpt_test3(); 2294drop function excpt_test4(); 2295 2296-- parameters of raise stmt can be expressions 2297create function raise_exprs() returns void as $$ 2298declare 2299 a integer[] = '{10,20,30}'; 2300 c varchar = 'xyz'; 2301 i integer; 2302begin 2303 i := 2; 2304 raise notice '%; %; %; %; %; %', a, a[i], c, (select c || 'abc'), row(10,'aaa',NULL,30), NULL; 2305end;$$ language plpgsql; 2306 2307select raise_exprs(); 2308drop function raise_exprs(); 2309 2310-- regression test: verify that multiple uses of same plpgsql datum within 2311-- a SQL command all get mapped to the same $n parameter. The return value 2312-- of the SELECT is not important, we only care that it doesn't fail with 2313-- a complaint about an ungrouped column reference. 2314create function multi_datum_use(p1 int) returns bool as $$ 2315declare 2316 x int; 2317 y int; 2318begin 2319 select into x,y unique1/p1, unique1/$1 from tenk1 group by unique1/p1; 2320 return x = y; 2321end$$ language plpgsql; 2322 2323select multi_datum_use(42); 2324 2325-- 2326-- Test STRICT limiter in both planned and EXECUTE invocations. 2327-- Note that a data-modifying query is quasi strict (disallow multi rows) 2328-- by default in the planned case, but not in EXECUTE. 2329-- 2330 2331create temp table foo (f1 int, f2 int); 2332 2333insert into foo values (1,2), (3,4); 2334 2335create or replace function stricttest() returns void as $$ 2336declare x record; 2337begin 2338 -- should work 2339 insert into foo values(5,6) returning * into x; 2340 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2341end$$ language plpgsql; 2342 2343select stricttest(); 2344 2345create or replace function stricttest() returns void as $$ 2346declare x record; 2347begin 2348 -- should fail due to implicit strict 2349 insert into foo values(7,8),(9,10) returning * into x; 2350 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2351end$$ language plpgsql; 2352 2353select stricttest(); 2354 2355create or replace function stricttest() returns void as $$ 2356declare x record; 2357begin 2358 -- should work 2359 execute 'insert into foo values(5,6) returning *' into x; 2360 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2361end$$ language plpgsql; 2362 2363select stricttest(); 2364 2365create or replace function stricttest() returns void as $$ 2366declare x record; 2367begin 2368 -- this should work since EXECUTE isn't as picky 2369 execute 'insert into foo values(7,8),(9,10) returning *' into x; 2370 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2371end$$ language plpgsql; 2372 2373select stricttest(); 2374 2375select * from foo; 2376 2377create or replace function stricttest() returns void as $$ 2378declare x record; 2379begin 2380 -- should work 2381 select * from foo where f1 = 3 into strict x; 2382 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2383end$$ language plpgsql; 2384 2385select stricttest(); 2386 2387create or replace function stricttest() returns void as $$ 2388declare x record; 2389begin 2390 -- should fail, no rows 2391 select * from foo where f1 = 0 into strict x; 2392 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2393end$$ language plpgsql; 2394 2395select stricttest(); 2396 2397create or replace function stricttest() returns void as $$ 2398declare x record; 2399begin 2400 -- should fail, too many rows 2401 select * from foo where f1 > 3 into strict x; 2402 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2403end$$ language plpgsql; 2404 2405select stricttest(); 2406 2407create or replace function stricttest() returns void as $$ 2408declare x record; 2409begin 2410 -- should work 2411 execute 'select * from foo where f1 = 3' into strict x; 2412 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2413end$$ language plpgsql; 2414 2415select stricttest(); 2416 2417create or replace function stricttest() returns void as $$ 2418declare x record; 2419begin 2420 -- should fail, no rows 2421 execute 'select * from foo where f1 = 0' into strict x; 2422 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2423end$$ language plpgsql; 2424 2425select stricttest(); 2426 2427create or replace function stricttest() returns void as $$ 2428declare x record; 2429begin 2430 -- should fail, too many rows 2431 execute 'select * from foo where f1 > 3' into strict x; 2432 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2433end$$ language plpgsql; 2434 2435select stricttest(); 2436 2437drop function stricttest(); 2438 2439-- test printing parameters after failure due to STRICT 2440 2441set plpgsql.print_strict_params to true; 2442 2443create or replace function stricttest() returns void as $$ 2444declare 2445x record; 2446p1 int := 2; 2447p3 text := 'foo'; 2448begin 2449 -- no rows 2450 select * from foo where f1 = p1 and f1::text = p3 into strict x; 2451 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2452end$$ language plpgsql; 2453 2454select stricttest(); 2455 2456create or replace function stricttest() returns void as $$ 2457declare 2458x record; 2459p1 int := 2; 2460p3 text := 'foo'; 2461begin 2462 -- too many rows 2463 select * from foo where f1 > p1 or f1::text = p3 into strict x; 2464 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2465end$$ language plpgsql; 2466 2467select stricttest(); 2468 2469create or replace function stricttest() returns void as $$ 2470declare x record; 2471begin 2472 -- too many rows, no params 2473 select * from foo where f1 > 3 into strict x; 2474 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2475end$$ language plpgsql; 2476 2477select stricttest(); 2478 2479create or replace function stricttest() returns void as $$ 2480declare x record; 2481begin 2482 -- no rows 2483 execute 'select * from foo where f1 = $1 or f1::text = $2' using 0, 'foo' into strict x; 2484 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2485end$$ language plpgsql; 2486 2487select stricttest(); 2488 2489create or replace function stricttest() returns void as $$ 2490declare x record; 2491begin 2492 -- too many rows 2493 execute 'select * from foo where f1 > $1' using 1 into strict x; 2494 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2495end$$ language plpgsql; 2496 2497select stricttest(); 2498 2499create or replace function stricttest() returns void as $$ 2500declare x record; 2501begin 2502 -- too many rows, no parameters 2503 execute 'select * from foo where f1 > 3' into strict x; 2504 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2505end$$ language plpgsql; 2506 2507select stricttest(); 2508 2509create or replace function stricttest() returns void as $$ 2510-- override the global 2511#print_strict_params off 2512declare 2513x record; 2514p1 int := 2; 2515p3 text := 'foo'; 2516begin 2517 -- too many rows 2518 select * from foo where f1 > p1 or f1::text = p3 into strict x; 2519 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2520end$$ language plpgsql; 2521 2522select stricttest(); 2523 2524reset plpgsql.print_strict_params; 2525 2526create or replace function stricttest() returns void as $$ 2527-- override the global 2528#print_strict_params on 2529declare 2530x record; 2531p1 int := 2; 2532p3 text := 'foo'; 2533begin 2534 -- too many rows 2535 select * from foo where f1 > p1 or f1::text = p3 into strict x; 2536 raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2; 2537end$$ language plpgsql; 2538 2539select stricttest(); 2540 2541-- test warnings and errors 2542set plpgsql.extra_warnings to 'all'; 2543set plpgsql.extra_warnings to 'none'; 2544set plpgsql.extra_errors to 'all'; 2545set plpgsql.extra_errors to 'none'; 2546 2547-- test warnings when shadowing a variable 2548 2549set plpgsql.extra_warnings to 'shadowed_variables'; 2550 2551-- simple shadowing of input and output parameters 2552create or replace function shadowtest(in1 int) 2553 returns table (out1 int) as $$ 2554declare 2555in1 int; 2556out1 int; 2557begin 2558end 2559$$ language plpgsql; 2560select shadowtest(1); 2561 2562set plpgsql.extra_warnings to 'shadowed_variables'; 2563select shadowtest(1); 2564create or replace function shadowtest(in1 int) 2565 returns table (out1 int) as $$ 2566declare 2567in1 int; 2568out1 int; 2569begin 2570end 2571$$ language plpgsql; 2572select shadowtest(1); 2573drop function shadowtest(int); 2574 2575-- shadowing in a second DECLARE block 2576create or replace function shadowtest() 2577 returns void as $$ 2578declare 2579f1 int; 2580begin 2581 declare 2582 f1 int; 2583 begin 2584 end; 2585end$$ language plpgsql; 2586drop function shadowtest(); 2587 2588-- several levels of shadowing 2589create or replace function shadowtest(in1 int) 2590 returns void as $$ 2591declare 2592in1 int; 2593begin 2594 declare 2595 in1 int; 2596 begin 2597 end; 2598end$$ language plpgsql; 2599drop function shadowtest(int); 2600 2601-- shadowing in cursor definitions 2602create or replace function shadowtest() 2603 returns void as $$ 2604declare 2605f1 int; 2606c1 cursor (f1 int) for select 1; 2607begin 2608end$$ language plpgsql; 2609drop function shadowtest(); 2610 2611-- test errors when shadowing a variable 2612 2613set plpgsql.extra_errors to 'shadowed_variables'; 2614 2615create or replace function shadowtest(f1 int) 2616 returns boolean as $$ 2617declare f1 int; begin return 1; end $$ language plpgsql; 2618 2619select shadowtest(1); 2620 2621reset plpgsql.extra_errors; 2622reset plpgsql.extra_warnings; 2623 2624create or replace function shadowtest(f1 int) 2625 returns boolean as $$ 2626declare f1 int; begin return 1; end $$ language plpgsql; 2627 2628select shadowtest(1); 2629 2630-- test scrollable cursor support 2631 2632create function sc_test() returns setof integer as $$ 2633declare 2634 c scroll cursor for select f1 from int4_tbl; 2635 x integer; 2636begin 2637 open c; 2638 fetch last from c into x; 2639 while found loop 2640 return next x; 2641 fetch prior from c into x; 2642 end loop; 2643 close c; 2644end; 2645$$ language plpgsql; 2646 2647select * from sc_test(); 2648 2649create or replace function sc_test() returns setof integer as $$ 2650declare 2651 c no scroll cursor for select f1 from int4_tbl; 2652 x integer; 2653begin 2654 open c; 2655 fetch last from c into x; 2656 while found loop 2657 return next x; 2658 fetch prior from c into x; 2659 end loop; 2660 close c; 2661end; 2662$$ language plpgsql; 2663 2664select * from sc_test(); -- fails because of NO SCROLL specification 2665 2666create or replace function sc_test() returns setof integer as $$ 2667declare 2668 c refcursor; 2669 x integer; 2670begin 2671 open c scroll for select f1 from int4_tbl; 2672 fetch last from c into x; 2673 while found loop 2674 return next x; 2675 fetch prior from c into x; 2676 end loop; 2677 close c; 2678end; 2679$$ language plpgsql; 2680 2681select * from sc_test(); 2682 2683create or replace function sc_test() returns setof integer as $$ 2684declare 2685 c refcursor; 2686 x integer; 2687begin 2688 open c scroll for execute 'select f1 from int4_tbl'; 2689 fetch last from c into x; 2690 while found loop 2691 return next x; 2692 fetch relative -2 from c into x; 2693 end loop; 2694 close c; 2695end; 2696$$ language plpgsql; 2697 2698select * from sc_test(); 2699 2700create or replace function sc_test() returns setof integer as $$ 2701declare 2702 c refcursor; 2703 x integer; 2704begin 2705 open c scroll for execute 'select f1 from int4_tbl'; 2706 fetch last from c into x; 2707 while found loop 2708 return next x; 2709 move backward 2 from c; 2710 fetch relative -1 from c into x; 2711 end loop; 2712 close c; 2713end; 2714$$ language plpgsql; 2715 2716select * from sc_test(); 2717 2718create or replace function sc_test() returns setof integer as $$ 2719declare 2720 c cursor for select * from generate_series(1, 10); 2721 x integer; 2722begin 2723 open c; 2724 loop 2725 move relative 2 in c; 2726 if not found then 2727 exit; 2728 end if; 2729 fetch next from c into x; 2730 if found then 2731 return next x; 2732 end if; 2733 end loop; 2734 close c; 2735end; 2736$$ language plpgsql; 2737 2738select * from sc_test(); 2739 2740create or replace function sc_test() returns setof integer as $$ 2741declare 2742 c cursor for select * from generate_series(1, 10); 2743 x integer; 2744begin 2745 open c; 2746 move forward all in c; 2747 fetch backward from c into x; 2748 if found then 2749 return next x; 2750 end if; 2751 close c; 2752end; 2753$$ language plpgsql; 2754 2755select * from sc_test(); 2756 2757drop function sc_test(); 2758 2759-- test qualified variable names 2760 2761create function pl_qual_names (param1 int) returns void as $$ 2762<<outerblock>> 2763declare 2764 param1 int := 1; 2765begin 2766 <<innerblock>> 2767 declare 2768 param1 int := 2; 2769 begin 2770 raise notice 'param1 = %', param1; 2771 raise notice 'pl_qual_names.param1 = %', pl_qual_names.param1; 2772 raise notice 'outerblock.param1 = %', outerblock.param1; 2773 raise notice 'innerblock.param1 = %', innerblock.param1; 2774 end; 2775end; 2776$$ language plpgsql; 2777 2778select pl_qual_names(42); 2779 2780drop function pl_qual_names(int); 2781 2782-- tests for RETURN QUERY 2783create function ret_query1(out int, out int) returns setof record as $$ 2784begin 2785 $1 := -1; 2786 $2 := -2; 2787 return next; 2788 return query select x + 1, x * 10 from generate_series(0, 10) s (x); 2789 return next; 2790end; 2791$$ language plpgsql; 2792 2793select * from ret_query1(); 2794 2795create type record_type as (x text, y int, z boolean); 2796 2797create or replace function ret_query2(lim int) returns setof record_type as $$ 2798begin 2799 return query select md5(s.x::text), s.x, s.x > 0 2800 from generate_series(-8, lim) s (x) where s.x % 2 = 0; 2801end; 2802$$ language plpgsql; 2803 2804select * from ret_query2(8); 2805 2806-- test EXECUTE USING 2807create function exc_using(int, text) returns int as $$ 2808declare i int; 2809begin 2810 for i in execute 'select * from generate_series(1,$1)' using $1+1 loop 2811 raise notice '%', i; 2812 end loop; 2813 execute 'select $2 + $2*3 + length($1)' into i using $2,$1; 2814 return i; 2815end 2816$$ language plpgsql; 2817 2818select exc_using(5, 'foobar'); 2819 2820drop function exc_using(int, text); 2821 2822create or replace function exc_using(int) returns void as $$ 2823declare 2824 c refcursor; 2825 i int; 2826begin 2827 open c for execute 'select * from generate_series(1,$1)' using $1+1; 2828 loop 2829 fetch c into i; 2830 exit when not found; 2831 raise notice '%', i; 2832 end loop; 2833 close c; 2834 return; 2835end; 2836$$ language plpgsql; 2837 2838select exc_using(5); 2839 2840drop function exc_using(int); 2841 2842-- test FOR-over-cursor 2843 2844create or replace function forc01() returns void as $$ 2845declare 2846 c cursor(r1 integer, r2 integer) 2847 for select * from generate_series(r1,r2) i; 2848 c2 cursor 2849 for select * from generate_series(41,43) i; 2850begin 2851 for r in c(5,7) loop 2852 raise notice '% from %', r.i, c; 2853 end loop; 2854 -- again, to test if cursor was closed properly 2855 for r in c(9,10) loop 2856 raise notice '% from %', r.i, c; 2857 end loop; 2858 -- and test a parameterless cursor 2859 for r in c2 loop 2860 raise notice '% from %', r.i, c2; 2861 end loop; 2862 -- and try it with a hand-assigned name 2863 raise notice 'after loop, c2 = %', c2; 2864 c2 := 'special_name'; 2865 for r in c2 loop 2866 raise notice '% from %', r.i, c2; 2867 end loop; 2868 raise notice 'after loop, c2 = %', c2; 2869 -- and try it with a generated name 2870 -- (which we can't show in the output because it's variable) 2871 c2 := null; 2872 for r in c2 loop 2873 raise notice '%', r.i; 2874 end loop; 2875 raise notice 'after loop, c2 = %', c2; 2876 return; 2877end; 2878$$ language plpgsql; 2879 2880select forc01(); 2881 2882-- try updating the cursor's current row 2883 2884create temp table forc_test as 2885 select n as i, n as j from generate_series(1,10) n; 2886 2887create or replace function forc01() returns void as $$ 2888declare 2889 c cursor for select * from forc_test; 2890begin 2891 for r in c loop 2892 raise notice '%, %', r.i, r.j; 2893 update forc_test set i = i * 100, j = r.j * 2 where current of c; 2894 end loop; 2895end; 2896$$ language plpgsql; 2897 2898select forc01(); 2899 2900select * from forc_test; 2901 2902-- same, with a cursor whose portal name doesn't match variable name 2903create or replace function forc01() returns void as $$ 2904declare 2905 c refcursor := 'fooled_ya'; 2906 r record; 2907begin 2908 open c for select * from forc_test; 2909 loop 2910 fetch c into r; 2911 exit when not found; 2912 raise notice '%, %', r.i, r.j; 2913 update forc_test set i = i * 100, j = r.j * 2 where current of c; 2914 end loop; 2915end; 2916$$ language plpgsql; 2917 2918select forc01(); 2919 2920select * from forc_test; 2921 2922drop function forc01(); 2923 2924-- fail because cursor has no query bound to it 2925 2926create or replace function forc_bad() returns void as $$ 2927declare 2928 c refcursor; 2929begin 2930 for r in c loop 2931 raise notice '%', r.i; 2932 end loop; 2933end; 2934$$ language plpgsql; 2935 2936-- test RETURN QUERY EXECUTE 2937 2938create or replace function return_dquery() 2939returns setof int as $$ 2940begin 2941 return query execute 'select * from (values(10),(20)) f'; 2942 return query execute 'select * from (values($1),($2)) f' using 40,50; 2943end; 2944$$ language plpgsql; 2945 2946select * from return_dquery(); 2947 2948drop function return_dquery(); 2949 2950-- test RETURN QUERY with dropped columns 2951 2952create table tabwithcols(a int, b int, c int, d int); 2953insert into tabwithcols values(10,20,30,40),(50,60,70,80); 2954 2955create or replace function returnqueryf() 2956returns setof tabwithcols as $$ 2957begin 2958 return query select * from tabwithcols; 2959 return query execute 'select * from tabwithcols'; 2960end; 2961$$ language plpgsql; 2962 2963select * from returnqueryf(); 2964 2965alter table tabwithcols drop column b; 2966 2967select * from returnqueryf(); 2968 2969alter table tabwithcols drop column d; 2970 2971select * from returnqueryf(); 2972 2973alter table tabwithcols add column d int; 2974 2975select * from returnqueryf(); 2976 2977drop function returnqueryf(); 2978drop table tabwithcols; 2979 2980-- 2981-- Tests for composite-type results 2982-- 2983 2984create type compostype as (x int, y varchar); 2985 2986-- test: use of variable of composite type in return statement 2987create or replace function compos() returns compostype as $$ 2988declare 2989 v compostype; 2990begin 2991 v := (1, 'hello'); 2992 return v; 2993end; 2994$$ language plpgsql; 2995 2996select compos(); 2997 2998-- test: use of variable of record type in return statement 2999create or replace function compos() returns compostype as $$ 3000declare 3001 v record; 3002begin 3003 v := (1, 'hello'::varchar); 3004 return v; 3005end; 3006$$ language plpgsql; 3007 3008select compos(); 3009 3010-- test: use of row expr in return statement 3011create or replace function compos() returns compostype as $$ 3012begin 3013 return (1, 'hello'::varchar); 3014end; 3015$$ language plpgsql; 3016 3017select compos(); 3018 3019-- this does not work currently (no implicit casting) 3020create or replace function compos() returns compostype as $$ 3021begin 3022 return (1, 'hello'); 3023end; 3024$$ language plpgsql; 3025 3026select compos(); 3027 3028-- ... but this does 3029create or replace function compos() returns compostype as $$ 3030begin 3031 return (1, 'hello')::compostype; 3032end; 3033$$ language plpgsql; 3034 3035select compos(); 3036 3037drop function compos(); 3038 3039-- test: return a row expr as record. 3040create or replace function composrec() returns record as $$ 3041declare 3042 v record; 3043begin 3044 v := (1, 'hello'); 3045 return v; 3046end; 3047$$ language plpgsql; 3048 3049select composrec(); 3050 3051-- test: return row expr in return statement. 3052create or replace function composrec() returns record as $$ 3053begin 3054 return (1, 'hello'); 3055end; 3056$$ language plpgsql; 3057 3058select composrec(); 3059 3060drop function composrec(); 3061 3062-- test: row expr in RETURN NEXT statement. 3063create or replace function compos() returns setof compostype as $$ 3064begin 3065 for i in 1..3 3066 loop 3067 return next (1, 'hello'::varchar); 3068 end loop; 3069 return next null::compostype; 3070 return next (2, 'goodbye')::compostype; 3071end; 3072$$ language plpgsql; 3073 3074select * from compos(); 3075 3076drop function compos(); 3077 3078-- test: use invalid expr in return statement. 3079create or replace function compos() returns compostype as $$ 3080begin 3081 return 1 + 1; 3082end; 3083$$ language plpgsql; 3084 3085select compos(); 3086 3087-- RETURN variable is a different code path ... 3088create or replace function compos() returns compostype as $$ 3089declare x int := 42; 3090begin 3091 return x; 3092end; 3093$$ language plpgsql; 3094 3095select * from compos(); 3096 3097drop function compos(); 3098 3099-- test: invalid use of composite variable in scalar-returning function 3100create or replace function compos() returns int as $$ 3101declare 3102 v compostype; 3103begin 3104 v := (1, 'hello'); 3105 return v; 3106end; 3107$$ language plpgsql; 3108 3109select compos(); 3110 3111-- test: invalid use of composite expression in scalar-returning function 3112create or replace function compos() returns int as $$ 3113begin 3114 return (1, 'hello')::compostype; 3115end; 3116$$ language plpgsql; 3117 3118select compos(); 3119 3120drop function compos(); 3121drop type compostype; 3122 3123-- 3124-- Tests for 8.4's new RAISE features 3125-- 3126 3127create or replace function raise_test() returns void as $$ 3128begin 3129 raise notice '% % %', 1, 2, 3 3130 using errcode = '55001', detail = 'some detail info', hint = 'some hint'; 3131 raise '% % %', 1, 2, 3 3132 using errcode = 'division_by_zero', detail = 'some detail info'; 3133end; 3134$$ language plpgsql; 3135 3136select raise_test(); 3137 3138-- Since we can't actually see the thrown SQLSTATE in default psql output, 3139-- test it like this; this also tests re-RAISE 3140 3141create or replace function raise_test() returns void as $$ 3142begin 3143 raise 'check me' 3144 using errcode = 'division_by_zero', detail = 'some detail info'; 3145 exception 3146 when others then 3147 raise notice 'SQLSTATE: % SQLERRM: %', sqlstate, sqlerrm; 3148 raise; 3149end; 3150$$ language plpgsql; 3151 3152select raise_test(); 3153 3154create or replace function raise_test() returns void as $$ 3155begin 3156 raise 'check me' 3157 using errcode = '1234F', detail = 'some detail info'; 3158 exception 3159 when others then 3160 raise notice 'SQLSTATE: % SQLERRM: %', sqlstate, sqlerrm; 3161 raise; 3162end; 3163$$ language plpgsql; 3164 3165select raise_test(); 3166 3167-- SQLSTATE specification in WHEN 3168create or replace function raise_test() returns void as $$ 3169begin 3170 raise 'check me' 3171 using errcode = '1234F', detail = 'some detail info'; 3172 exception 3173 when sqlstate '1234F' then 3174 raise notice 'SQLSTATE: % SQLERRM: %', sqlstate, sqlerrm; 3175 raise; 3176end; 3177$$ language plpgsql; 3178 3179select raise_test(); 3180 3181create or replace function raise_test() returns void as $$ 3182begin 3183 raise division_by_zero using detail = 'some detail info'; 3184 exception 3185 when others then 3186 raise notice 'SQLSTATE: % SQLERRM: %', sqlstate, sqlerrm; 3187 raise; 3188end; 3189$$ language plpgsql; 3190 3191select raise_test(); 3192 3193create or replace function raise_test() returns void as $$ 3194begin 3195 raise division_by_zero; 3196end; 3197$$ language plpgsql; 3198 3199select raise_test(); 3200 3201create or replace function raise_test() returns void as $$ 3202begin 3203 raise sqlstate '1234F'; 3204end; 3205$$ language plpgsql; 3206 3207select raise_test(); 3208 3209create or replace function raise_test() returns void as $$ 3210begin 3211 raise division_by_zero using message = 'custom' || ' message'; 3212end; 3213$$ language plpgsql; 3214 3215select raise_test(); 3216 3217create or replace function raise_test() returns void as $$ 3218begin 3219 raise using message = 'custom' || ' message', errcode = '22012'; 3220end; 3221$$ language plpgsql; 3222 3223select raise_test(); 3224 3225-- conflict on message 3226create or replace function raise_test() returns void as $$ 3227begin 3228 raise notice 'some message' using message = 'custom' || ' message', errcode = '22012'; 3229end; 3230$$ language plpgsql; 3231 3232select raise_test(); 3233 3234-- conflict on errcode 3235create or replace function raise_test() returns void as $$ 3236begin 3237 raise division_by_zero using message = 'custom' || ' message', errcode = '22012'; 3238end; 3239$$ language plpgsql; 3240 3241select raise_test(); 3242 3243-- nothing to re-RAISE 3244create or replace function raise_test() returns void as $$ 3245begin 3246 raise; 3247end; 3248$$ language plpgsql; 3249 3250select raise_test(); 3251 3252-- test access to exception data 3253create function zero_divide() returns int as $$ 3254declare v int := 0; 3255begin 3256 return 10 / v; 3257end; 3258$$ language plpgsql; 3259 3260create or replace function raise_test() returns void as $$ 3261begin 3262 raise exception 'custom exception' 3263 using detail = 'some detail of custom exception', 3264 hint = 'some hint related to custom exception'; 3265end; 3266$$ language plpgsql; 3267 3268create function stacked_diagnostics_test() returns void as $$ 3269declare _sqlstate text; 3270 _message text; 3271 _context text; 3272begin 3273 perform zero_divide(); 3274exception when others then 3275 get stacked diagnostics 3276 _sqlstate = returned_sqlstate, 3277 _message = message_text, 3278 _context = pg_exception_context; 3279 raise notice 'sqlstate: %, message: %, context: [%]', 3280 _sqlstate, _message, replace(_context, E'\n', ' <- '); 3281end; 3282$$ language plpgsql; 3283 3284select stacked_diagnostics_test(); 3285 3286create or replace function stacked_diagnostics_test() returns void as $$ 3287declare _detail text; 3288 _hint text; 3289 _message text; 3290begin 3291 perform raise_test(); 3292exception when others then 3293 get stacked diagnostics 3294 _message = message_text, 3295 _detail = pg_exception_detail, 3296 _hint = pg_exception_hint; 3297 raise notice 'message: %, detail: %, hint: %', _message, _detail, _hint; 3298end; 3299$$ language plpgsql; 3300 3301select stacked_diagnostics_test(); 3302 3303-- fail, cannot use stacked diagnostics statement outside handler 3304create or replace function stacked_diagnostics_test() returns void as $$ 3305declare _detail text; 3306 _hint text; 3307 _message text; 3308begin 3309 get stacked diagnostics 3310 _message = message_text, 3311 _detail = pg_exception_detail, 3312 _hint = pg_exception_hint; 3313 raise notice 'message: %, detail: %, hint: %', _message, _detail, _hint; 3314end; 3315$$ language plpgsql; 3316 3317select stacked_diagnostics_test(); 3318 3319drop function zero_divide(); 3320drop function stacked_diagnostics_test(); 3321 3322-- check cases where implicit SQLSTATE variable could be confused with 3323-- SQLSTATE as a keyword, cf bug #5524 3324create or replace function raise_test() returns void as $$ 3325begin 3326 perform 1/0; 3327exception 3328 when sqlstate '22012' then 3329 raise notice using message = sqlstate; 3330 raise sqlstate '22012' using message = 'substitute message'; 3331end; 3332$$ language plpgsql; 3333 3334select raise_test(); 3335 3336drop function raise_test(); 3337 3338-- test passing column_name, constraint_name, datatype_name, table_name 3339-- and schema_name error fields 3340 3341create or replace function stacked_diagnostics_test() returns void as $$ 3342declare _column_name text; 3343 _constraint_name text; 3344 _datatype_name text; 3345 _table_name text; 3346 _schema_name text; 3347begin 3348 raise exception using 3349 column = '>>some column name<<', 3350 constraint = '>>some constraint name<<', 3351 datatype = '>>some datatype name<<', 3352 table = '>>some table name<<', 3353 schema = '>>some schema name<<'; 3354exception when others then 3355 get stacked diagnostics 3356 _column_name = column_name, 3357 _constraint_name = constraint_name, 3358 _datatype_name = pg_datatype_name, 3359 _table_name = table_name, 3360 _schema_name = schema_name; 3361 raise notice 'column %, constraint %, type %, table %, schema %', 3362 _column_name, _constraint_name, _datatype_name, _table_name, _schema_name; 3363end; 3364$$ language plpgsql; 3365 3366select stacked_diagnostics_test(); 3367 3368drop function stacked_diagnostics_test(); 3369 3370-- test variadic functions 3371 3372create or replace function vari(variadic int[]) 3373returns void as $$ 3374begin 3375 for i in array_lower($1,1)..array_upper($1,1) loop 3376 raise notice '%', $1[i]; 3377 end loop; end; 3378$$ language plpgsql; 3379 3380select vari(1,2,3,4,5); 3381select vari(3,4,5); 3382select vari(variadic array[5,6,7]); 3383 3384drop function vari(int[]); 3385 3386-- coercion test 3387create or replace function pleast(variadic numeric[]) 3388returns numeric as $$ 3389declare aux numeric = $1[array_lower($1,1)]; 3390begin 3391 for i in array_lower($1,1)+1..array_upper($1,1) loop 3392 if $1[i] < aux then aux := $1[i]; end if; 3393 end loop; 3394 return aux; 3395end; 3396$$ language plpgsql immutable strict; 3397 3398select pleast(10,1,2,3,-16); 3399select pleast(10.2,2.2,-1.1); 3400select pleast(10.2,10, -20); 3401select pleast(10,20, -1.0); 3402 3403-- in case of conflict, non-variadic version is preferred 3404create or replace function pleast(numeric) 3405returns numeric as $$ 3406begin 3407 raise notice 'non-variadic function called'; 3408 return $1; 3409end; 3410$$ language plpgsql immutable strict; 3411 3412select pleast(10); 3413 3414drop function pleast(numeric[]); 3415drop function pleast(numeric); 3416 3417-- test table functions 3418 3419create function tftest(int) returns table(a int, b int) as $$ 3420begin 3421 return query select $1, $1+i from generate_series(1,5) g(i); 3422end; 3423$$ language plpgsql immutable strict; 3424 3425select * from tftest(10); 3426 3427create or replace function tftest(a1 int) returns table(a int, b int) as $$ 3428begin 3429 a := a1; b := a1 + 1; 3430 return next; 3431 a := a1 * 10; b := a1 * 10 + 1; 3432 return next; 3433end; 3434$$ language plpgsql immutable strict; 3435 3436select * from tftest(10); 3437 3438drop function tftest(int); 3439 3440create or replace function rttest() 3441returns setof int as $$ 3442declare rc int; 3443 rca int[]; 3444begin 3445 return query values(10),(20); 3446 get diagnostics rc = row_count; 3447 raise notice '% %', found, rc; 3448 return query select * from (values(10),(20)) f(a) where false; 3449 get diagnostics rc = row_count; 3450 raise notice '% %', found, rc; 3451 return query execute 'values(10),(20)'; 3452 -- just for fun, let's use array elements as targets 3453 get diagnostics rca[1] = row_count; 3454 raise notice '% %', found, rca[1]; 3455 return query execute 'select * from (values(10),(20)) f(a) where false'; 3456 get diagnostics rca[2] = row_count; 3457 raise notice '% %', found, rca[2]; 3458end; 3459$$ language plpgsql; 3460 3461select * from rttest(); 3462 3463drop function rttest(); 3464 3465-- Test for proper cleanup at subtransaction exit. This example 3466-- exposed a bug in PG 8.2. 3467 3468CREATE FUNCTION leaker_1(fail BOOL) RETURNS INTEGER AS $$ 3469DECLARE 3470 v_var INTEGER; 3471BEGIN 3472 BEGIN 3473 v_var := (leaker_2(fail)).error_code; 3474 EXCEPTION 3475 WHEN others THEN RETURN 0; 3476 END; 3477 RETURN 1; 3478END; 3479$$ LANGUAGE plpgsql; 3480 3481CREATE FUNCTION leaker_2(fail BOOL, OUT error_code INTEGER, OUT new_id INTEGER) 3482 RETURNS RECORD AS $$ 3483BEGIN 3484 IF fail THEN 3485 RAISE EXCEPTION 'fail ...'; 3486 END IF; 3487 error_code := 1; 3488 new_id := 1; 3489 RETURN; 3490END; 3491$$ LANGUAGE plpgsql; 3492 3493SELECT * FROM leaker_1(false); 3494SELECT * FROM leaker_1(true); 3495 3496DROP FUNCTION leaker_1(bool); 3497DROP FUNCTION leaker_2(bool); 3498 3499-- Test for appropriate cleanup of non-simple expression evaluations 3500-- (bug in all versions prior to August 2010) 3501 3502CREATE FUNCTION nonsimple_expr_test() RETURNS text[] AS $$ 3503DECLARE 3504 arr text[]; 3505 lr text; 3506 i integer; 3507BEGIN 3508 arr := array[array['foo','bar'], array['baz', 'quux']]; 3509 lr := 'fool'; 3510 i := 1; 3511 -- use sub-SELECTs to make expressions non-simple 3512 arr[(SELECT i)][(SELECT i+1)] := (SELECT lr); 3513 RETURN arr; 3514END; 3515$$ LANGUAGE plpgsql; 3516 3517SELECT nonsimple_expr_test(); 3518 3519DROP FUNCTION nonsimple_expr_test(); 3520 3521CREATE FUNCTION nonsimple_expr_test() RETURNS integer AS $$ 3522declare 3523 i integer NOT NULL := 0; 3524begin 3525 begin 3526 i := (SELECT NULL::integer); -- should throw error 3527 exception 3528 WHEN OTHERS THEN 3529 i := (SELECT 1::integer); 3530 end; 3531 return i; 3532end; 3533$$ LANGUAGE plpgsql; 3534 3535SELECT nonsimple_expr_test(); 3536 3537DROP FUNCTION nonsimple_expr_test(); 3538 3539-- 3540-- Test cases involving recursion and error recovery in simple expressions 3541-- (bugs in all versions before October 2010). The problems are most 3542-- easily exposed by mutual recursion between plpgsql and sql functions. 3543-- 3544 3545create function recurse(float8) returns float8 as 3546$$ 3547begin 3548 if ($1 > 0) then 3549 return sql_recurse($1 - 1); 3550 else 3551 return $1; 3552 end if; 3553end; 3554$$ language plpgsql; 3555 3556-- "limit" is to prevent this from being inlined 3557create function sql_recurse(float8) returns float8 as 3558$$ select recurse($1) limit 1; $$ language sql; 3559 3560select recurse(10); 3561 3562create function error1(text) returns text language sql as 3563$$ SELECT relname::text FROM pg_class c WHERE c.oid = $1::regclass $$; 3564 3565create function error2(p_name_table text) returns text language plpgsql as $$ 3566begin 3567 return error1(p_name_table); 3568end$$; 3569 3570BEGIN; 3571create table public.stuffs (stuff text); 3572SAVEPOINT a; 3573select error2('nonexistent.stuffs'); 3574ROLLBACK TO a; 3575select error2('public.stuffs'); 3576rollback; 3577 3578drop function error2(p_name_table text); 3579drop function error1(text); 3580 3581-- Test for proper handling of cast-expression caching 3582 3583create function sql_to_date(integer) returns date as $$ 3584select $1::text::date 3585$$ language sql immutable strict; 3586 3587create cast (integer as date) with function sql_to_date(integer) as assignment; 3588 3589create function cast_invoker(integer) returns date as $$ 3590begin 3591 return $1; 3592end$$ language plpgsql; 3593 3594select cast_invoker(20150717); 3595select cast_invoker(20150718); -- second call crashed in pre-release 9.5 3596 3597begin; 3598select cast_invoker(20150717); 3599select cast_invoker(20150718); 3600savepoint s1; 3601select cast_invoker(20150718); 3602select cast_invoker(-1); -- fails 3603rollback to savepoint s1; 3604select cast_invoker(20150719); 3605select cast_invoker(20150720); 3606commit; 3607 3608drop function cast_invoker(integer); 3609drop function sql_to_date(integer) cascade; 3610 3611-- Test handling of cast cache inside DO blocks 3612-- (to check the original crash case, this must be a cast not previously 3613-- used in this session) 3614 3615begin; 3616do $$ declare x text[]; begin x := '{1.23, 4.56}'::numeric[]; end $$; 3617do $$ declare x text[]; begin x := '{1.23, 4.56}'::numeric[]; end $$; 3618end; 3619 3620-- Test for consistent reporting of error context 3621 3622create function fail() returns int language plpgsql as $$ 3623begin 3624 return 1/0; 3625end 3626$$; 3627 3628select fail(); 3629select fail(); 3630 3631drop function fail(); 3632 3633-- Test handling of string literals. 3634 3635set standard_conforming_strings = off; 3636 3637create or replace function strtest() returns text as $$ 3638begin 3639 raise notice 'foo\\bar\041baz'; 3640 return 'foo\\bar\041baz'; 3641end 3642$$ language plpgsql; 3643 3644select strtest(); 3645 3646create or replace function strtest() returns text as $$ 3647begin 3648 raise notice E'foo\\bar\041baz'; 3649 return E'foo\\bar\041baz'; 3650end 3651$$ language plpgsql; 3652 3653select strtest(); 3654 3655set standard_conforming_strings = on; 3656 3657create or replace function strtest() returns text as $$ 3658begin 3659 raise notice 'foo\\bar\041baz\'; 3660 return 'foo\\bar\041baz\'; 3661end 3662$$ language plpgsql; 3663 3664select strtest(); 3665 3666create or replace function strtest() returns text as $$ 3667begin 3668 raise notice E'foo\\bar\041baz'; 3669 return E'foo\\bar\041baz'; 3670end 3671$$ language plpgsql; 3672 3673select strtest(); 3674 3675drop function strtest(); 3676 3677-- Test anonymous code blocks. 3678 3679DO $$ 3680DECLARE r record; 3681BEGIN 3682 FOR r IN SELECT rtrim(roomno) AS roomno, comment FROM Room ORDER BY roomno 3683 LOOP 3684 RAISE NOTICE '%, %', r.roomno, r.comment; 3685 END LOOP; 3686END$$; 3687 3688-- these are to check syntax error reporting 3689DO LANGUAGE plpgsql $$begin return 1; end$$; 3690 3691DO $$ 3692DECLARE r record; 3693BEGIN 3694 FOR r IN SELECT rtrim(roomno) AS roomno, foo FROM Room ORDER BY roomno 3695 LOOP 3696 RAISE NOTICE '%, %', r.roomno, r.comment; 3697 END LOOP; 3698END$$; 3699 3700-- Check handling of errors thrown from/into anonymous code blocks. 3701do $outer$ 3702begin 3703 for i in 1..10 loop 3704 begin 3705 execute $ex$ 3706 do $$ 3707 declare x int = 0; 3708 begin 3709 x := 1 / x; 3710 end; 3711 $$; 3712 $ex$; 3713 exception when division_by_zero then 3714 raise notice 'caught division by zero'; 3715 end; 3716 end loop; 3717end; 3718$outer$; 3719 3720-- Check variable scoping -- a var is not available in its own or prior 3721-- default expressions. 3722 3723create function scope_test() returns int as $$ 3724declare x int := 42; 3725begin 3726 declare y int := x + 1; 3727 x int := x + 2; 3728 begin 3729 return x * 100 + y; 3730 end; 3731end; 3732$$ language plpgsql; 3733 3734select scope_test(); 3735 3736drop function scope_test(); 3737 3738-- Check handling of conflicts between plpgsql vars and table columns. 3739 3740set plpgsql.variable_conflict = error; 3741 3742create function conflict_test() returns setof int8_tbl as $$ 3743declare r record; 3744 q1 bigint := 42; 3745begin 3746 for r in select q1,q2 from int8_tbl loop 3747 return next r; 3748 end loop; 3749end; 3750$$ language plpgsql; 3751 3752select * from conflict_test(); 3753 3754create or replace function conflict_test() returns setof int8_tbl as $$ 3755#variable_conflict use_variable 3756declare r record; 3757 q1 bigint := 42; 3758begin 3759 for r in select q1,q2 from int8_tbl loop 3760 return next r; 3761 end loop; 3762end; 3763$$ language plpgsql; 3764 3765select * from conflict_test(); 3766 3767create or replace function conflict_test() returns setof int8_tbl as $$ 3768#variable_conflict use_column 3769declare r record; 3770 q1 bigint := 42; 3771begin 3772 for r in select q1,q2 from int8_tbl loop 3773 return next r; 3774 end loop; 3775end; 3776$$ language plpgsql; 3777 3778select * from conflict_test(); 3779 3780drop function conflict_test(); 3781 3782-- Check that an unreserved keyword can be used as a variable name 3783 3784create function unreserved_test() returns int as $$ 3785declare 3786 forward int := 21; 3787begin 3788 forward := forward * 2; 3789 return forward; 3790end 3791$$ language plpgsql; 3792 3793select unreserved_test(); 3794 3795create or replace function unreserved_test() returns int as $$ 3796declare 3797 return int := 42; 3798begin 3799 return := return + 1; 3800 return return; 3801end 3802$$ language plpgsql; 3803 3804select unreserved_test(); 3805 3806drop function unreserved_test(); 3807 3808-- 3809-- Test FOREACH over arrays 3810-- 3811 3812create function foreach_test(anyarray) 3813returns void as $$ 3814declare x int; 3815begin 3816 foreach x in array $1 3817 loop 3818 raise notice '%', x; 3819 end loop; 3820 end; 3821$$ language plpgsql; 3822 3823select foreach_test(ARRAY[1,2,3,4]); 3824select foreach_test(ARRAY[[1,2],[3,4]]); 3825 3826create or replace function foreach_test(anyarray) 3827returns void as $$ 3828declare x int; 3829begin 3830 foreach x slice 1 in array $1 3831 loop 3832 raise notice '%', x; 3833 end loop; 3834 end; 3835$$ language plpgsql; 3836 3837-- should fail 3838select foreach_test(ARRAY[1,2,3,4]); 3839select foreach_test(ARRAY[[1,2],[3,4]]); 3840 3841create or replace function foreach_test(anyarray) 3842returns void as $$ 3843declare x int[]; 3844begin 3845 foreach x slice 1 in array $1 3846 loop 3847 raise notice '%', x; 3848 end loop; 3849 end; 3850$$ language plpgsql; 3851 3852select foreach_test(ARRAY[1,2,3,4]); 3853select foreach_test(ARRAY[[1,2],[3,4]]); 3854 3855-- higher level of slicing 3856create or replace function foreach_test(anyarray) 3857returns void as $$ 3858declare x int[]; 3859begin 3860 foreach x slice 2 in array $1 3861 loop 3862 raise notice '%', x; 3863 end loop; 3864 end; 3865$$ language plpgsql; 3866 3867-- should fail 3868select foreach_test(ARRAY[1,2,3,4]); 3869-- ok 3870select foreach_test(ARRAY[[1,2],[3,4]]); 3871select foreach_test(ARRAY[[[1,2]],[[3,4]]]); 3872 3873create type xy_tuple AS (x int, y int); 3874 3875-- iteration over array of records 3876create or replace function foreach_test(anyarray) 3877returns void as $$ 3878declare r record; 3879begin 3880 foreach r in array $1 3881 loop 3882 raise notice '%', r; 3883 end loop; 3884 end; 3885$$ language plpgsql; 3886 3887select foreach_test(ARRAY[(10,20),(40,69),(35,78)]::xy_tuple[]); 3888select foreach_test(ARRAY[[(10,20),(40,69)],[(35,78),(88,76)]]::xy_tuple[]); 3889 3890create or replace function foreach_test(anyarray) 3891returns void as $$ 3892declare x int; y int; 3893begin 3894 foreach x, y in array $1 3895 loop 3896 raise notice 'x = %, y = %', x, y; 3897 end loop; 3898 end; 3899$$ language plpgsql; 3900 3901select foreach_test(ARRAY[(10,20),(40,69),(35,78)]::xy_tuple[]); 3902select foreach_test(ARRAY[[(10,20),(40,69)],[(35,78),(88,76)]]::xy_tuple[]); 3903 3904-- slicing over array of composite types 3905create or replace function foreach_test(anyarray) 3906returns void as $$ 3907declare x xy_tuple[]; 3908begin 3909 foreach x slice 1 in array $1 3910 loop 3911 raise notice '%', x; 3912 end loop; 3913 end; 3914$$ language plpgsql; 3915 3916select foreach_test(ARRAY[(10,20),(40,69),(35,78)]::xy_tuple[]); 3917select foreach_test(ARRAY[[(10,20),(40,69)],[(35,78),(88,76)]]::xy_tuple[]); 3918 3919drop function foreach_test(anyarray); 3920drop type xy_tuple; 3921 3922-- 3923-- Assorted tests for array subscript assignment 3924-- 3925 3926create temp table rtype (id int, ar text[]); 3927 3928create function arrayassign1() returns text[] language plpgsql as $$ 3929declare 3930 r record; 3931begin 3932 r := row(12, '{foo,bar,baz}')::rtype; 3933 r.ar[2] := 'replace'; 3934 return r.ar; 3935end$$; 3936 3937select arrayassign1(); 3938select arrayassign1(); -- try again to exercise internal caching 3939 3940create domain orderedarray as int[2] 3941 constraint sorted check (value[1] < value[2]); 3942 3943select '{1,2}'::orderedarray; 3944select '{2,1}'::orderedarray; -- fail 3945 3946create function testoa(x1 int, x2 int, x3 int) returns orderedarray 3947language plpgsql as $$ 3948declare res orderedarray; 3949begin 3950 res := array[x1, x2]; 3951 res[2] := x3; 3952 return res; 3953end$$; 3954 3955select testoa(1,2,3); 3956select testoa(1,2,3); -- try again to exercise internal caching 3957select testoa(2,1,3); -- fail at initial assign 3958select testoa(1,2,1); -- fail at update 3959 3960drop function arrayassign1(); 3961drop function testoa(x1 int, x2 int, x3 int); 3962 3963 3964-- 3965-- Test handling of expanded arrays 3966-- 3967 3968create function returns_rw_array(int) returns int[] 3969language plpgsql as $$ 3970 declare r int[]; 3971 begin r := array[$1, $1]; return r; end; 3972$$ stable; 3973 3974create function consumes_rw_array(int[]) returns int 3975language plpgsql as $$ 3976 begin return $1[1]; end; 3977$$ stable; 3978 3979select consumes_rw_array(returns_rw_array(42)); 3980 3981-- bug #14174 3982explain (verbose, costs off) 3983select i, a from 3984 (select returns_rw_array(1) as a offset 0) ss, 3985 lateral consumes_rw_array(a) i; 3986 3987select i, a from 3988 (select returns_rw_array(1) as a offset 0) ss, 3989 lateral consumes_rw_array(a) i; 3990 3991explain (verbose, costs off) 3992select consumes_rw_array(a), a from returns_rw_array(1) a; 3993 3994select consumes_rw_array(a), a from returns_rw_array(1) a; 3995 3996explain (verbose, costs off) 3997select consumes_rw_array(a), a from 3998 (values (returns_rw_array(1)), (returns_rw_array(2))) v(a); 3999 4000select consumes_rw_array(a), a from 4001 (values (returns_rw_array(1)), (returns_rw_array(2))) v(a); 4002 4003do $$ 4004declare a int[] := array[1,2]; 4005begin 4006 a := a || 3; 4007 raise notice 'a = %', a; 4008end$$; 4009 4010 4011-- 4012-- Test access to call stack 4013-- 4014 4015create function inner_func(int) 4016returns int as $$ 4017declare _context text; 4018begin 4019 get diagnostics _context = pg_context; 4020 raise notice '***%***', _context; 4021 -- lets do it again, just for fun.. 4022 get diagnostics _context = pg_context; 4023 raise notice '***%***', _context; 4024 raise notice 'lets make sure we didnt break anything'; 4025 return 2 * $1; 4026end; 4027$$ language plpgsql; 4028 4029create or replace function outer_func(int) 4030returns int as $$ 4031declare 4032 myresult int; 4033begin 4034 raise notice 'calling down into inner_func()'; 4035 myresult := inner_func($1); 4036 raise notice 'inner_func() done'; 4037 return myresult; 4038end; 4039$$ language plpgsql; 4040 4041create or replace function outer_outer_func(int) 4042returns int as $$ 4043declare 4044 myresult int; 4045begin 4046 raise notice 'calling down into outer_func()'; 4047 myresult := outer_func($1); 4048 raise notice 'outer_func() done'; 4049 return myresult; 4050end; 4051$$ language plpgsql; 4052 4053select outer_outer_func(10); 4054-- repeated call should to work 4055select outer_outer_func(20); 4056 4057drop function outer_outer_func(int); 4058drop function outer_func(int); 4059drop function inner_func(int); 4060 4061-- access to call stack from exception 4062create function inner_func(int) 4063returns int as $$ 4064declare 4065 _context text; 4066 sx int := 5; 4067begin 4068 begin 4069 perform sx / 0; 4070 exception 4071 when division_by_zero then 4072 get diagnostics _context = pg_context; 4073 raise notice '***%***', _context; 4074 end; 4075 4076 -- lets do it again, just for fun.. 4077 get diagnostics _context = pg_context; 4078 raise notice '***%***', _context; 4079 raise notice 'lets make sure we didnt break anything'; 4080 return 2 * $1; 4081end; 4082$$ language plpgsql; 4083 4084create or replace function outer_func(int) 4085returns int as $$ 4086declare 4087 myresult int; 4088begin 4089 raise notice 'calling down into inner_func()'; 4090 myresult := inner_func($1); 4091 raise notice 'inner_func() done'; 4092 return myresult; 4093end; 4094$$ language plpgsql; 4095 4096create or replace function outer_outer_func(int) 4097returns int as $$ 4098declare 4099 myresult int; 4100begin 4101 raise notice 'calling down into outer_func()'; 4102 myresult := outer_func($1); 4103 raise notice 'outer_func() done'; 4104 return myresult; 4105end; 4106$$ language plpgsql; 4107 4108select outer_outer_func(10); 4109-- repeated call should to work 4110select outer_outer_func(20); 4111 4112drop function outer_outer_func(int); 4113drop function outer_func(int); 4114drop function inner_func(int); 4115 4116-- 4117-- Test ASSERT 4118-- 4119 4120do $$ 4121begin 4122 assert 1=1; -- should succeed 4123end; 4124$$; 4125 4126do $$ 4127begin 4128 assert 1=0; -- should fail 4129end; 4130$$; 4131 4132do $$ 4133begin 4134 assert NULL; -- should fail 4135end; 4136$$; 4137 4138-- check controlling GUC 4139set plpgsql.check_asserts = off; 4140do $$ 4141begin 4142 assert 1=0; -- won't be tested 4143end; 4144$$; 4145reset plpgsql.check_asserts; 4146 4147-- test custom message 4148do $$ 4149declare var text := 'some value'; 4150begin 4151 assert 1=0, format('assertion failed, var = "%s"', var); 4152end; 4153$$; 4154 4155-- ensure assertions are not trapped by 'others' 4156do $$ 4157begin 4158 assert 1=0, 'unhandled assertion'; 4159exception when others then 4160 null; -- do nothing 4161end; 4162$$; 4163 4164-- Test use of plpgsql in a domain check constraint (cf. bug #14414) 4165 4166create function plpgsql_domain_check(val int) returns boolean as $$ 4167begin return val > 0; end 4168$$ language plpgsql immutable; 4169 4170create domain plpgsql_domain as integer check(plpgsql_domain_check(value)); 4171 4172do $$ 4173declare v_test plpgsql_domain; 4174begin 4175 v_test := 1; 4176end; 4177$$; 4178 4179do $$ 4180declare v_test plpgsql_domain := 1; 4181begin 4182 v_test := 0; -- fail 4183end; 4184$$; 4185 4186-- Test handling of expanded array passed to a domain constraint (bug #14472) 4187 4188create function plpgsql_arr_domain_check(val int[]) returns boolean as $$ 4189begin return val[1] > 0; end 4190$$ language plpgsql immutable; 4191 4192create domain plpgsql_arr_domain as int[] check(plpgsql_arr_domain_check(value)); 4193 4194do $$ 4195declare v_test plpgsql_arr_domain; 4196begin 4197 v_test := array[1]; 4198 v_test := v_test || 2; 4199end; 4200$$; 4201 4202do $$ 4203declare v_test plpgsql_arr_domain := array[1]; 4204begin 4205 v_test := 0 || v_test; -- fail 4206end; 4207$$; 4208 4209-- 4210-- test usage of transition tables in AFTER triggers 4211-- 4212 4213CREATE TABLE transition_table_base (id int PRIMARY KEY, val text); 4214 4215CREATE FUNCTION transition_table_base_ins_func() 4216 RETURNS trigger 4217 LANGUAGE plpgsql 4218AS $$ 4219DECLARE 4220 t text; 4221 l text; 4222BEGIN 4223 t = ''; 4224 FOR l IN EXECUTE 4225 $q$ 4226 EXPLAIN (TIMING off, COSTS off, VERBOSE on) 4227 SELECT * FROM newtable 4228 $q$ LOOP 4229 t = t || l || E'\n'; 4230 END LOOP; 4231 4232 RAISE INFO '%', t; 4233 RETURN new; 4234END; 4235$$; 4236 4237CREATE TRIGGER transition_table_base_ins_trig 4238 AFTER INSERT ON transition_table_base 4239 REFERENCING OLD TABLE AS oldtable NEW TABLE AS newtable 4240 FOR EACH STATEMENT 4241 EXECUTE PROCEDURE transition_table_base_ins_func(); 4242 4243CREATE TRIGGER transition_table_base_ins_trig 4244 AFTER INSERT ON transition_table_base 4245 REFERENCING NEW TABLE AS newtable 4246 FOR EACH STATEMENT 4247 EXECUTE PROCEDURE transition_table_base_ins_func(); 4248 4249INSERT INTO transition_table_base VALUES (1, 'One'), (2, 'Two'); 4250INSERT INTO transition_table_base VALUES (3, 'Three'), (4, 'Four'); 4251 4252CREATE OR REPLACE FUNCTION transition_table_base_upd_func() 4253 RETURNS trigger 4254 LANGUAGE plpgsql 4255AS $$ 4256DECLARE 4257 t text; 4258 l text; 4259BEGIN 4260 t = ''; 4261 FOR l IN EXECUTE 4262 $q$ 4263 EXPLAIN (TIMING off, COSTS off, VERBOSE on) 4264 SELECT * FROM oldtable ot FULL JOIN newtable nt USING (id) 4265 $q$ LOOP 4266 t = t || l || E'\n'; 4267 END LOOP; 4268 4269 RAISE INFO '%', t; 4270 RETURN new; 4271END; 4272$$; 4273 4274CREATE TRIGGER transition_table_base_upd_trig 4275 AFTER UPDATE ON transition_table_base 4276 REFERENCING OLD TABLE AS oldtable NEW TABLE AS newtable 4277 FOR EACH STATEMENT 4278 EXECUTE PROCEDURE transition_table_base_upd_func(); 4279 4280UPDATE transition_table_base 4281 SET val = '*' || val || '*' 4282 WHERE id BETWEEN 2 AND 3; 4283 4284CREATE TABLE transition_table_level1 4285( 4286 level1_no serial NOT NULL , 4287 level1_node_name varchar(255), 4288 PRIMARY KEY (level1_no) 4289) WITHOUT OIDS; 4290 4291CREATE TABLE transition_table_level2 4292( 4293 level2_no serial NOT NULL , 4294 parent_no int NOT NULL, 4295 level1_node_name varchar(255), 4296 PRIMARY KEY (level2_no) 4297) WITHOUT OIDS; 4298 4299CREATE TABLE transition_table_status 4300( 4301 level int NOT NULL, 4302 node_no int NOT NULL, 4303 status int, 4304 PRIMARY KEY (level, node_no) 4305) WITHOUT OIDS; 4306 4307CREATE FUNCTION transition_table_level1_ri_parent_del_func() 4308 RETURNS TRIGGER 4309 LANGUAGE plpgsql 4310AS $$ 4311 DECLARE n bigint; 4312 BEGIN 4313 PERFORM FROM p JOIN transition_table_level2 c ON c.parent_no = p.level1_no; 4314 IF FOUND THEN 4315 RAISE EXCEPTION 'RI error'; 4316 END IF; 4317 RETURN NULL; 4318 END; 4319$$; 4320 4321CREATE TRIGGER transition_table_level1_ri_parent_del_trigger 4322 AFTER DELETE ON transition_table_level1 4323 REFERENCING OLD TABLE AS p 4324 FOR EACH STATEMENT EXECUTE PROCEDURE 4325 transition_table_level1_ri_parent_del_func(); 4326 4327CREATE FUNCTION transition_table_level1_ri_parent_upd_func() 4328 RETURNS TRIGGER 4329 LANGUAGE plpgsql 4330AS $$ 4331 DECLARE 4332 x int; 4333 BEGIN 4334 WITH p AS (SELECT level1_no, sum(delta) cnt 4335 FROM (SELECT level1_no, 1 AS delta FROM i 4336 UNION ALL 4337 SELECT level1_no, -1 AS delta FROM d) w 4338 GROUP BY level1_no 4339 HAVING sum(delta) < 0) 4340 SELECT level1_no 4341 FROM p JOIN transition_table_level2 c ON c.parent_no = p.level1_no 4342 INTO x; 4343 IF FOUND THEN 4344 RAISE EXCEPTION 'RI error'; 4345 END IF; 4346 RETURN NULL; 4347 END; 4348$$; 4349 4350CREATE TRIGGER transition_table_level1_ri_parent_upd_trigger 4351 AFTER UPDATE ON transition_table_level1 4352 REFERENCING OLD TABLE AS d NEW TABLE AS i 4353 FOR EACH STATEMENT EXECUTE PROCEDURE 4354 transition_table_level1_ri_parent_upd_func(); 4355 4356CREATE FUNCTION transition_table_level2_ri_child_insupd_func() 4357 RETURNS TRIGGER 4358 LANGUAGE plpgsql 4359AS $$ 4360 BEGIN 4361 PERFORM FROM i 4362 LEFT JOIN transition_table_level1 p 4363 ON p.level1_no IS NOT NULL AND p.level1_no = i.parent_no 4364 WHERE p.level1_no IS NULL; 4365 IF FOUND THEN 4366 RAISE EXCEPTION 'RI error'; 4367 END IF; 4368 RETURN NULL; 4369 END; 4370$$; 4371 4372CREATE TRIGGER transition_table_level2_ri_child_ins_trigger 4373 AFTER INSERT ON transition_table_level2 4374 REFERENCING NEW TABLE AS i 4375 FOR EACH STATEMENT EXECUTE PROCEDURE 4376 transition_table_level2_ri_child_insupd_func(); 4377 4378CREATE TRIGGER transition_table_level2_ri_child_upd_trigger 4379 AFTER UPDATE ON transition_table_level2 4380 REFERENCING NEW TABLE AS i 4381 FOR EACH STATEMENT EXECUTE PROCEDURE 4382 transition_table_level2_ri_child_insupd_func(); 4383 4384-- create initial test data 4385INSERT INTO transition_table_level1 (level1_no) 4386 SELECT generate_series(1,200); 4387ANALYZE transition_table_level1; 4388 4389INSERT INTO transition_table_level2 (level2_no, parent_no) 4390 SELECT level2_no, level2_no / 50 + 1 AS parent_no 4391 FROM generate_series(1,9999) level2_no; 4392ANALYZE transition_table_level2; 4393 4394INSERT INTO transition_table_status (level, node_no, status) 4395 SELECT 1, level1_no, 0 FROM transition_table_level1; 4396 4397INSERT INTO transition_table_status (level, node_no, status) 4398 SELECT 2, level2_no, 0 FROM transition_table_level2; 4399ANALYZE transition_table_status; 4400 4401INSERT INTO transition_table_level1(level1_no) 4402 SELECT generate_series(201,1000); 4403ANALYZE transition_table_level1; 4404 4405-- behave reasonably if someone tries to modify a transition table 4406CREATE FUNCTION transition_table_level2_bad_usage_func() 4407 RETURNS TRIGGER 4408 LANGUAGE plpgsql 4409AS $$ 4410 BEGIN 4411 INSERT INTO dx VALUES (1000000, 1000000, 'x'); 4412 RETURN NULL; 4413 END; 4414$$; 4415 4416CREATE TRIGGER transition_table_level2_bad_usage_trigger 4417 AFTER DELETE ON transition_table_level2 4418 REFERENCING OLD TABLE AS dx 4419 FOR EACH STATEMENT EXECUTE PROCEDURE 4420 transition_table_level2_bad_usage_func(); 4421 4422DELETE FROM transition_table_level2 4423 WHERE level2_no BETWEEN 301 AND 305; 4424 4425DROP TRIGGER transition_table_level2_bad_usage_trigger 4426 ON transition_table_level2; 4427 4428-- attempt modifications which would break RI (should all fail) 4429DELETE FROM transition_table_level1 4430 WHERE level1_no = 25; 4431 4432UPDATE transition_table_level1 SET level1_no = -1 4433 WHERE level1_no = 30; 4434 4435INSERT INTO transition_table_level2 (level2_no, parent_no) 4436 VALUES (10000, 10000); 4437 4438UPDATE transition_table_level2 SET parent_no = 2000 4439 WHERE level2_no = 40; 4440 4441 4442-- attempt modifications which would not break RI (should all succeed) 4443DELETE FROM transition_table_level1 4444 WHERE level1_no BETWEEN 201 AND 1000; 4445 4446DELETE FROM transition_table_level1 4447 WHERE level1_no BETWEEN 100000000 AND 100000010; 4448 4449SELECT count(*) FROM transition_table_level1; 4450 4451DELETE FROM transition_table_level2 4452 WHERE level2_no BETWEEN 211 AND 220; 4453 4454SELECT count(*) FROM transition_table_level2; 4455 4456CREATE TABLE alter_table_under_transition_tables 4457( 4458 id int PRIMARY KEY, 4459 name text 4460); 4461 4462CREATE FUNCTION alter_table_under_transition_tables_upd_func() 4463 RETURNS TRIGGER 4464 LANGUAGE plpgsql 4465AS $$ 4466BEGIN 4467 RAISE WARNING 'old table = %, new table = %', 4468 (SELECT string_agg(id || '=' || name, ',') FROM d), 4469 (SELECT string_agg(id || '=' || name, ',') FROM i); 4470 RAISE NOTICE 'one = %', (SELECT 1 FROM alter_table_under_transition_tables LIMIT 1); 4471 RETURN NULL; 4472END; 4473$$; 4474 4475-- should fail, TRUNCATE is not compatible with transition tables 4476CREATE TRIGGER alter_table_under_transition_tables_upd_trigger 4477 AFTER TRUNCATE OR UPDATE ON alter_table_under_transition_tables 4478 REFERENCING OLD TABLE AS d NEW TABLE AS i 4479 FOR EACH STATEMENT EXECUTE PROCEDURE 4480 alter_table_under_transition_tables_upd_func(); 4481 4482-- should work 4483CREATE TRIGGER alter_table_under_transition_tables_upd_trigger 4484 AFTER UPDATE ON alter_table_under_transition_tables 4485 REFERENCING OLD TABLE AS d NEW TABLE AS i 4486 FOR EACH STATEMENT EXECUTE PROCEDURE 4487 alter_table_under_transition_tables_upd_func(); 4488 4489INSERT INTO alter_table_under_transition_tables 4490 VALUES (1, '1'), (2, '2'), (3, '3'); 4491UPDATE alter_table_under_transition_tables 4492 SET name = name || name; 4493 4494-- now change 'name' to an integer to see what happens... 4495ALTER TABLE alter_table_under_transition_tables 4496 ALTER COLUMN name TYPE int USING name::integer; 4497UPDATE alter_table_under_transition_tables 4498 SET name = (name::text || name::text)::integer; 4499 4500-- now drop column 'name' 4501ALTER TABLE alter_table_under_transition_tables 4502 DROP column name; 4503UPDATE alter_table_under_transition_tables 4504 SET id = id; 4505 4506-- 4507-- Test multiple reference to a transition table 4508-- 4509 4510CREATE TABLE multi_test (i int); 4511INSERT INTO multi_test VALUES (1); 4512 4513CREATE OR REPLACE FUNCTION multi_test_trig() RETURNS trigger 4514LANGUAGE plpgsql AS $$ 4515BEGIN 4516 RAISE NOTICE 'count = %', (SELECT COUNT(*) FROM new_test); 4517 RAISE NOTICE 'count union = %', 4518 (SELECT COUNT(*) 4519 FROM (SELECT * FROM new_test UNION ALL SELECT * FROM new_test) ss); 4520 RETURN NULL; 4521END$$; 4522 4523CREATE TRIGGER my_trigger AFTER UPDATE ON multi_test 4524 REFERENCING NEW TABLE AS new_test OLD TABLE as old_test 4525 FOR EACH STATEMENT EXECUTE PROCEDURE multi_test_trig(); 4526 4527UPDATE multi_test SET i = i; 4528 4529DROP TABLE multi_test; 4530DROP FUNCTION multi_test_trig(); 4531 4532-- 4533-- Check type parsing and record fetching from partitioned tables 4534-- 4535 4536CREATE TABLE partitioned_table (a int, b text) PARTITION BY LIST (a); 4537CREATE TABLE pt_part1 PARTITION OF partitioned_table FOR VALUES IN (1); 4538CREATE TABLE pt_part2 PARTITION OF partitioned_table FOR VALUES IN (2); 4539 4540INSERT INTO partitioned_table VALUES (1, 'Row 1'); 4541INSERT INTO partitioned_table VALUES (2, 'Row 2'); 4542 4543CREATE OR REPLACE FUNCTION get_from_partitioned_table(partitioned_table.a%type) 4544RETURNS partitioned_table AS $$ 4545DECLARE 4546 a_val partitioned_table.a%TYPE; 4547 result partitioned_table%ROWTYPE; 4548BEGIN 4549 a_val := $1; 4550 SELECT * INTO result FROM partitioned_table WHERE a = a_val; 4551 RETURN result; 4552END; $$ LANGUAGE plpgsql; 4553 4554SELECT * FROM get_from_partitioned_table(1) AS t; 4555 4556CREATE OR REPLACE FUNCTION list_partitioned_table() 4557RETURNS SETOF partitioned_table.a%TYPE AS $$ 4558DECLARE 4559 row partitioned_table%ROWTYPE; 4560 a_val partitioned_table.a%TYPE; 4561BEGIN 4562 FOR row IN SELECT * FROM partitioned_table ORDER BY a LOOP 4563 a_val := row.a; 4564 RETURN NEXT a_val; 4565 END LOOP; 4566 RETURN; 4567END; $$ LANGUAGE plpgsql; 4568 4569SELECT * FROM list_partitioned_table() AS t; 4570 4571-- 4572-- Check argument name is used instead of $n in error message 4573-- 4574CREATE FUNCTION fx(x WSlot) RETURNS void AS $$ 4575BEGIN 4576 GET DIAGNOSTICS x = ROW_COUNT; 4577 RETURN; 4578END; $$ LANGUAGE plpgsql; 4579