-- -- PLPGSQL -- -- Scenario: -- -- A building with a modern TP cable installation where any -- of the wall connectors can be used to plug in phones, -- ethernet interfaces or local office hubs. The backside -- of the wall connectors is wired to one of several patch- -- fields in the building. -- -- In the patchfields, there are hubs and all the slots -- representing the wall connectors. In addition there are -- slots that can represent a phone line from the central -- phone system. -- -- Triggers ensure consistency of the patching information. -- -- Functions are used to build up powerful views that let -- you look behind the wall when looking at a patchfield -- or into a room. -- create table Room ( roomno char(8), comment text ); create unique index Room_rno on Room using btree (roomno bpchar_ops); create table WSlot ( slotname char(20), roomno char(8), slotlink char(20), backlink char(20) ); create unique index WSlot_name on WSlot using btree (slotname bpchar_ops); create table PField ( name text, comment text ); create unique index PField_name on PField using btree (name text_ops); create table PSlot ( slotname char(20), pfname text, slotlink char(20), backlink char(20) ); create unique index PSlot_name on PSlot using btree (slotname bpchar_ops); create table PLine ( slotname char(20), phonenumber char(20), comment text, backlink char(20) ); create unique index PLine_name on PLine using btree (slotname bpchar_ops); create table Hub ( name char(14), comment text, nslots integer ); create unique index Hub_name on Hub using btree (name bpchar_ops); create table HSlot ( slotname char(20), hubname char(14), slotno integer, slotlink char(20) ); create unique index HSlot_name on HSlot using btree (slotname bpchar_ops); create index HSlot_hubname on HSlot using btree (hubname bpchar_ops); create table System ( name text, comment text ); create unique index System_name on System using btree (name text_ops); create table IFace ( slotname char(20), sysname text, ifname text, slotlink char(20) ); create unique index IFace_name on IFace using btree (slotname bpchar_ops); create table PHone ( slotname char(20), comment text, slotlink char(20) ); create unique index PHone_name on PHone using btree (slotname bpchar_ops); -- ************************************************************ -- * -- * Trigger procedures and functions for the patchfield -- * test of PL/pgSQL -- * -- ************************************************************ -- ************************************************************ -- * AFTER UPDATE on Room -- * - If room no changes let wall slots follow -- ************************************************************ create function tg_room_au() returns trigger as ' begin if new.roomno != old.roomno then update WSlot set roomno = new.roomno where roomno = old.roomno; end if; return new; end; ' language 'plpgsql'; create trigger tg_room_au after update on Room for each row execute procedure tg_room_au(); -- ************************************************************ -- * AFTER DELETE on Room -- * - delete wall slots in this room -- ************************************************************ create function tg_room_ad() returns trigger as ' begin delete from WSlot where roomno = old.roomno; return old; end; ' language 'plpgsql'; create trigger tg_room_ad after delete on Room for each row execute procedure tg_room_ad(); -- ************************************************************ -- * BEFORE INSERT or UPDATE on WSlot -- * - Check that room exists -- ************************************************************ create function tg_wslot_biu() returns trigger as ' begin if count(*) = 0 from Room where roomno = new.roomno then raise exception ''Room % does not exist'', new.roomno; end if; return new; end; ' language 'plpgsql'; create trigger tg_wslot_biu before insert or update on WSlot for each row execute procedure tg_wslot_biu(); -- ************************************************************ -- * AFTER UPDATE on PField -- * - Let PSlots of this field follow -- ************************************************************ create function tg_pfield_au() returns trigger as ' begin if new.name != old.name then update PSlot set pfname = new.name where pfname = old.name; end if; return new; end; ' language 'plpgsql'; create trigger tg_pfield_au after update on PField for each row execute procedure tg_pfield_au(); -- ************************************************************ -- * AFTER DELETE on PField -- * - Remove all slots of this patchfield -- ************************************************************ create function tg_pfield_ad() returns trigger as ' begin delete from PSlot where pfname = old.name; return old; end; ' language 'plpgsql'; create trigger tg_pfield_ad after delete on PField for each row execute procedure tg_pfield_ad(); -- ************************************************************ -- * BEFORE INSERT or UPDATE on PSlot -- * - Ensure that our patchfield does exist -- ************************************************************ create function tg_pslot_biu() returns trigger as ' declare pfrec record; rename new to ps; begin select into pfrec * from PField where name = ps.pfname; if not found then raise exception ''Patchfield "%" does not exist'', ps.pfname; end if; return ps; end; ' language 'plpgsql'; create trigger tg_pslot_biu before insert or update on PSlot for each row execute procedure tg_pslot_biu(); -- ************************************************************ -- * AFTER UPDATE on System -- * - If system name changes let interfaces follow -- ************************************************************ create function tg_system_au() returns trigger as ' begin if new.name != old.name then update IFace set sysname = new.name where sysname = old.name; end if; return new; end; ' language 'plpgsql'; create trigger tg_system_au after update on System for each row execute procedure tg_system_au(); -- ************************************************************ -- * BEFORE INSERT or UPDATE on IFace -- * - set the slotname to IF.sysname.ifname -- ************************************************************ create function tg_iface_biu() returns trigger as ' declare sname text; sysrec record; begin select into sysrec * from system where name = new.sysname; if not found then raise exception ''system "%" does not exist'', new.sysname; end if; sname := ''IF.'' || new.sysname; sname := sname || ''.''; sname := sname || new.ifname; if length(sname) > 20 then raise exception ''IFace slotname "%" too long (20 char max)'', sname; end if; new.slotname := sname; return new; end; ' language 'plpgsql'; create trigger tg_iface_biu before insert or update on IFace for each row execute procedure tg_iface_biu(); -- ************************************************************ -- * AFTER INSERT or UPDATE or DELETE on Hub -- * - insert/delete/rename slots as required -- ************************************************************ create function tg_hub_a() returns trigger as ' declare hname text; dummy integer; begin if tg_op = ''INSERT'' then dummy := tg_hub_adjustslots(new.name, 0, new.nslots); return new; end if; if tg_op = ''UPDATE'' then if new.name != old.name then update HSlot set hubname = new.name where hubname = old.name; end if; dummy := tg_hub_adjustslots(new.name, old.nslots, new.nslots); return new; end if; if tg_op = ''DELETE'' then dummy := tg_hub_adjustslots(old.name, old.nslots, 0); return old; end if; end; ' language 'plpgsql'; create trigger tg_hub_a after insert or update or delete on Hub for each row execute procedure tg_hub_a(); -- ************************************************************ -- * Support function to add/remove slots of Hub -- ************************************************************ create function tg_hub_adjustslots(bpchar, integer, integer) returns integer as ' declare hname alias for $1; oldnslots alias for $2; newnslots alias for $3; begin if newnslots = oldnslots then return 0; end if; if newnslots < oldnslots then delete from HSlot where hubname = hname and slotno > newnslots; return 0; end if; for i in oldnslots + 1 .. newnslots loop insert into HSlot (slotname, hubname, slotno, slotlink) values (''HS.dummy'', hname, i, ''''); end loop; return 0; end; ' language 'plpgsql'; -- Test comments COMMENT ON FUNCTION tg_hub_adjustslots_wrong(bpchar, integer, integer) IS 'function with args'; ERROR: function tg_hub_adjustslots_wrong(character, integer, integer) does not exist COMMENT ON FUNCTION tg_hub_adjustslots(bpchar, integer, integer) IS 'function with args'; COMMENT ON FUNCTION tg_hub_adjustslots(bpchar, integer, integer) IS NULL; -- ************************************************************ -- * BEFORE INSERT or UPDATE on HSlot -- * - prevent from manual manipulation -- * - set the slotname to HS.hubname.slotno -- ************************************************************ create function tg_hslot_biu() returns trigger as ' declare sname text; xname HSlot.slotname%TYPE; hubrec record; begin select into hubrec * from Hub where name = new.hubname; if not found then raise exception ''no manual manipulation of HSlot''; end if; if new.slotno < 1 or new.slotno > hubrec.nslots then raise exception ''no manual manipulation of HSlot''; end if; if tg_op = ''UPDATE'' then if new.hubname != old.hubname then if count(*) > 0 from Hub where name = old.hubname then raise exception ''no manual manipulation of HSlot''; end if; end if; end if; sname := ''HS.'' || trim(new.hubname); sname := sname || ''.''; sname := sname || new.slotno::text; if length(sname) > 20 then raise exception ''HSlot slotname "%" too long (20 char max)'', sname; end if; new.slotname := sname; return new; end; ' language 'plpgsql'; create trigger tg_hslot_biu before insert or update on HSlot for each row execute procedure tg_hslot_biu(); -- ************************************************************ -- * BEFORE DELETE on HSlot -- * - prevent from manual manipulation -- ************************************************************ create function tg_hslot_bd() returns trigger as ' declare hubrec record; begin select into hubrec * from Hub where name = old.hubname; if not found then return old; end if; if old.slotno > hubrec.nslots then return old; end if; raise exception ''no manual manipulation of HSlot''; end; ' language 'plpgsql'; create trigger tg_hslot_bd before delete on HSlot for each row execute procedure tg_hslot_bd(); -- ************************************************************ -- * BEFORE INSERT on all slots -- * - Check name prefix -- ************************************************************ create function tg_chkslotname() returns trigger as ' begin if substr(new.slotname, 1, 2) != tg_argv[0] then raise exception ''slotname must begin with %'', tg_argv[0]; end if; return new; end; ' language 'plpgsql'; create trigger tg_chkslotname before insert on PSlot for each row execute procedure tg_chkslotname('PS'); create trigger tg_chkslotname before insert on WSlot for each row execute procedure tg_chkslotname('WS'); create trigger tg_chkslotname before insert on PLine for each row execute procedure tg_chkslotname('PL'); create trigger tg_chkslotname before insert on IFace for each row execute procedure tg_chkslotname('IF'); create trigger tg_chkslotname before insert on PHone for each row execute procedure tg_chkslotname('PH'); -- ************************************************************ -- * BEFORE INSERT or UPDATE on all slots with slotlink -- * - Set slotlink to empty string if NULL value given -- ************************************************************ create function tg_chkslotlink() returns trigger as ' begin if new.slotlink isnull then new.slotlink := ''''; end if; return new; end; ' language 'plpgsql'; create trigger tg_chkslotlink before insert or update on PSlot for each row execute procedure tg_chkslotlink(); create trigger tg_chkslotlink before insert or update on WSlot for each row execute procedure tg_chkslotlink(); create trigger tg_chkslotlink before insert or update on IFace for each row execute procedure tg_chkslotlink(); create trigger tg_chkslotlink before insert or update on HSlot for each row execute procedure tg_chkslotlink(); create trigger tg_chkslotlink before insert or update on PHone for each row execute procedure tg_chkslotlink(); -- ************************************************************ -- * BEFORE INSERT or UPDATE on all slots with backlink -- * - Set backlink to empty string if NULL value given -- ************************************************************ create function tg_chkbacklink() returns trigger as ' begin if new.backlink isnull then new.backlink := ''''; end if; return new; end; ' language 'plpgsql'; create trigger tg_chkbacklink before insert or update on PSlot for each row execute procedure tg_chkbacklink(); create trigger tg_chkbacklink before insert or update on WSlot for each row execute procedure tg_chkbacklink(); create trigger tg_chkbacklink before insert or update on PLine for each row execute procedure tg_chkbacklink(); -- ************************************************************ -- * BEFORE UPDATE on PSlot -- * - do delete/insert instead of update if name changes -- ************************************************************ create function tg_pslot_bu() returns trigger as ' begin if new.slotname != old.slotname then delete from PSlot where slotname = old.slotname; insert into PSlot ( slotname, pfname, slotlink, backlink ) values ( new.slotname, new.pfname, new.slotlink, new.backlink ); return null; end if; return new; end; ' language 'plpgsql'; create trigger tg_pslot_bu before update on PSlot for each row execute procedure tg_pslot_bu(); -- ************************************************************ -- * BEFORE UPDATE on WSlot -- * - do delete/insert instead of update if name changes -- ************************************************************ create function tg_wslot_bu() returns trigger as ' begin if new.slotname != old.slotname then delete from WSlot where slotname = old.slotname; insert into WSlot ( slotname, roomno, slotlink, backlink ) values ( new.slotname, new.roomno, new.slotlink, new.backlink ); return null; end if; return new; end; ' language 'plpgsql'; create trigger tg_wslot_bu before update on WSlot for each row execute procedure tg_Wslot_bu(); -- ************************************************************ -- * BEFORE UPDATE on PLine -- * - do delete/insert instead of update if name changes -- ************************************************************ create function tg_pline_bu() returns trigger as ' begin if new.slotname != old.slotname then delete from PLine where slotname = old.slotname; insert into PLine ( slotname, phonenumber, comment, backlink ) values ( new.slotname, new.phonenumber, new.comment, new.backlink ); return null; end if; return new; end; ' language 'plpgsql'; create trigger tg_pline_bu before update on PLine for each row execute procedure tg_pline_bu(); -- ************************************************************ -- * BEFORE UPDATE on IFace -- * - do delete/insert instead of update if name changes -- ************************************************************ create function tg_iface_bu() returns trigger as ' begin if new.slotname != old.slotname then delete from IFace where slotname = old.slotname; insert into IFace ( slotname, sysname, ifname, slotlink ) values ( new.slotname, new.sysname, new.ifname, new.slotlink ); return null; end if; return new; end; ' language 'plpgsql'; create trigger tg_iface_bu before update on IFace for each row execute procedure tg_iface_bu(); -- ************************************************************ -- * BEFORE UPDATE on HSlot -- * - do delete/insert instead of update if name changes -- ************************************************************ create function tg_hslot_bu() returns trigger as ' begin if new.slotname != old.slotname or new.hubname != old.hubname then delete from HSlot where slotname = old.slotname; insert into HSlot ( slotname, hubname, slotno, slotlink ) values ( new.slotname, new.hubname, new.slotno, new.slotlink ); return null; end if; return new; end; ' language 'plpgsql'; create trigger tg_hslot_bu before update on HSlot for each row execute procedure tg_hslot_bu(); -- ************************************************************ -- * BEFORE UPDATE on PHone -- * - do delete/insert instead of update if name changes -- ************************************************************ create function tg_phone_bu() returns trigger as ' begin if new.slotname != old.slotname then delete from PHone where slotname = old.slotname; insert into PHone ( slotname, comment, slotlink ) values ( new.slotname, new.comment, new.slotlink ); return null; end if; return new; end; ' language 'plpgsql'; create trigger tg_phone_bu before update on PHone for each row execute procedure tg_phone_bu(); -- ************************************************************ -- * AFTER INSERT or UPDATE or DELETE on slot with backlink -- * - Ensure that the opponent correctly points back to us -- ************************************************************ create function tg_backlink_a() returns trigger as ' declare dummy integer; begin if tg_op = ''INSERT'' then if new.backlink != '''' then dummy := tg_backlink_set(new.backlink, new.slotname); end if; return new; end if; if tg_op = ''UPDATE'' then if new.backlink != old.backlink then if old.backlink != '''' then dummy := tg_backlink_unset(old.backlink, old.slotname); end if; if new.backlink != '''' then dummy := tg_backlink_set(new.backlink, new.slotname); end if; else if new.slotname != old.slotname and new.backlink != '''' then dummy := tg_slotlink_set(new.backlink, new.slotname); end if; end if; return new; end if; if tg_op = ''DELETE'' then if old.backlink != '''' then dummy := tg_backlink_unset(old.backlink, old.slotname); end if; return old; end if; end; ' language 'plpgsql'; create trigger tg_backlink_a after insert or update or delete on PSlot for each row execute procedure tg_backlink_a('PS'); create trigger tg_backlink_a after insert or update or delete on WSlot for each row execute procedure tg_backlink_a('WS'); create trigger tg_backlink_a after insert or update or delete on PLine for each row execute procedure tg_backlink_a('PL'); -- ************************************************************ -- * Support function to set the opponents backlink field -- * if it does not already point to the requested slot -- ************************************************************ create function tg_backlink_set(bpchar, bpchar) returns integer as ' declare myname alias for $1; blname alias for $2; mytype char(2); link char(4); rec record; begin mytype := substr(myname, 1, 2); link := mytype || substr(blname, 1, 2); if link = ''PLPL'' then raise exception ''backlink between two phone lines does not make sense''; end if; if link in (''PLWS'', ''WSPL'') then raise exception ''direct link of phone line to wall slot not permitted''; end if; if mytype = ''PS'' then select into rec * from PSlot where slotname = myname; if not found then raise exception ''% does not exist'', myname; end if; if rec.backlink != blname then update PSlot set backlink = blname where slotname = myname; end if; return 0; end if; if mytype = ''WS'' then select into rec * from WSlot where slotname = myname; if not found then raise exception ''% does not exist'', myname; end if; if rec.backlink != blname then update WSlot set backlink = blname where slotname = myname; end if; return 0; end if; if mytype = ''PL'' then select into rec * from PLine where slotname = myname; if not found then raise exception ''% does not exist'', myname; end if; if rec.backlink != blname then update PLine set backlink = blname where slotname = myname; end if; return 0; end if; raise exception ''illegal backlink beginning with %'', mytype; end; ' language 'plpgsql'; -- ************************************************************ -- * Support function to clear out the backlink field if -- * it still points to specific slot -- ************************************************************ create function tg_backlink_unset(bpchar, bpchar) returns integer as ' declare myname alias for $1; blname alias for $2; mytype char(2); rec record; begin mytype := substr(myname, 1, 2); if mytype = ''PS'' then select into rec * from PSlot where slotname = myname; if not found then return 0; end if; if rec.backlink = blname then update PSlot set backlink = '''' where slotname = myname; end if; return 0; end if; if mytype = ''WS'' then select into rec * from WSlot where slotname = myname; if not found then return 0; end if; if rec.backlink = blname then update WSlot set backlink = '''' where slotname = myname; end if; return 0; end if; if mytype = ''PL'' then select into rec * from PLine where slotname = myname; if not found then return 0; end if; if rec.backlink = blname then update PLine set backlink = '''' where slotname = myname; end if; return 0; end if; end; ' language 'plpgsql'; -- ************************************************************ -- * AFTER INSERT or UPDATE or DELETE on slot with slotlink -- * - Ensure that the opponent correctly points back to us -- ************************************************************ create function tg_slotlink_a() returns trigger as ' declare dummy integer; begin if tg_op = ''INSERT'' then if new.slotlink != '''' then dummy := tg_slotlink_set(new.slotlink, new.slotname); end if; return new; end if; if tg_op = ''UPDATE'' then if new.slotlink != old.slotlink then if old.slotlink != '''' then dummy := tg_slotlink_unset(old.slotlink, old.slotname); end if; if new.slotlink != '''' then dummy := tg_slotlink_set(new.slotlink, new.slotname); end if; else if new.slotname != old.slotname and new.slotlink != '''' then dummy := tg_slotlink_set(new.slotlink, new.slotname); end if; end if; return new; end if; if tg_op = ''DELETE'' then if old.slotlink != '''' then dummy := tg_slotlink_unset(old.slotlink, old.slotname); end if; return old; end if; end; ' language 'plpgsql'; create trigger tg_slotlink_a after insert or update or delete on PSlot for each row execute procedure tg_slotlink_a('PS'); create trigger tg_slotlink_a after insert or update or delete on WSlot for each row execute procedure tg_slotlink_a('WS'); create trigger tg_slotlink_a after insert or update or delete on IFace for each row execute procedure tg_slotlink_a('IF'); create trigger tg_slotlink_a after insert or update or delete on HSlot for each row execute procedure tg_slotlink_a('HS'); create trigger tg_slotlink_a after insert or update or delete on PHone for each row execute procedure tg_slotlink_a('PH'); -- ************************************************************ -- * Support function to set the opponents slotlink field -- * if it does not already point to the requested slot -- ************************************************************ create function tg_slotlink_set(bpchar, bpchar) returns integer as ' declare myname alias for $1; blname alias for $2; mytype char(2); link char(4); rec record; begin mytype := substr(myname, 1, 2); link := mytype || substr(blname, 1, 2); if link = ''PHPH'' then raise exception ''slotlink between two phones does not make sense''; end if; if link in (''PHHS'', ''HSPH'') then raise exception ''link of phone to hub does not make sense''; end if; if link in (''PHIF'', ''IFPH'') then raise exception ''link of phone to hub does not make sense''; end if; if link in (''PSWS'', ''WSPS'') then raise exception ''slotlink from patchslot to wallslot not permitted''; end if; if mytype = ''PS'' then select into rec * from PSlot where slotname = myname; if not found then raise exception ''% does not exist'', myname; end if; if rec.slotlink != blname then update PSlot set slotlink = blname where slotname = myname; end if; return 0; end if; if mytype = ''WS'' then select into rec * from WSlot where slotname = myname; if not found then raise exception ''% does not exist'', myname; end if; if rec.slotlink != blname then update WSlot set slotlink = blname where slotname = myname; end if; return 0; end if; if mytype = ''IF'' then select into rec * from IFace where slotname = myname; if not found then raise exception ''% does not exist'', myname; end if; if rec.slotlink != blname then update IFace set slotlink = blname where slotname = myname; end if; return 0; end if; if mytype = ''HS'' then select into rec * from HSlot where slotname = myname; if not found then raise exception ''% does not exist'', myname; end if; if rec.slotlink != blname then update HSlot set slotlink = blname where slotname = myname; end if; return 0; end if; if mytype = ''PH'' then select into rec * from PHone where slotname = myname; if not found then raise exception ''% does not exist'', myname; end if; if rec.slotlink != blname then update PHone set slotlink = blname where slotname = myname; end if; return 0; end if; raise exception ''illegal slotlink beginning with %'', mytype; end; ' language 'plpgsql'; -- ************************************************************ -- * Support function to clear out the slotlink field if -- * it still points to specific slot -- ************************************************************ create function tg_slotlink_unset(bpchar, bpchar) returns integer as ' declare myname alias for $1; blname alias for $2; mytype char(2); rec record; begin mytype := substr(myname, 1, 2); if mytype = ''PS'' then select into rec * from PSlot where slotname = myname; if not found then return 0; end if; if rec.slotlink = blname then update PSlot set slotlink = '''' where slotname = myname; end if; return 0; end if; if mytype = ''WS'' then select into rec * from WSlot where slotname = myname; if not found then return 0; end if; if rec.slotlink = blname then update WSlot set slotlink = '''' where slotname = myname; end if; return 0; end if; if mytype = ''IF'' then select into rec * from IFace where slotname = myname; if not found then return 0; end if; if rec.slotlink = blname then update IFace set slotlink = '''' where slotname = myname; end if; return 0; end if; if mytype = ''HS'' then select into rec * from HSlot where slotname = myname; if not found then return 0; end if; if rec.slotlink = blname then update HSlot set slotlink = '''' where slotname = myname; end if; return 0; end if; if mytype = ''PH'' then select into rec * from PHone where slotname = myname; if not found then return 0; end if; if rec.slotlink = blname then update PHone set slotlink = '''' where slotname = myname; end if; return 0; end if; end; ' language 'plpgsql'; -- ************************************************************ -- * Describe the backside of a patchfield slot -- ************************************************************ create function pslot_backlink_view(bpchar) returns text as ' <> declare rec record; bltype char(2); retval text; begin select into rec * from PSlot where slotname = $1; if not found then return ''''; end if; if rec.backlink = '''' then return ''-''; end if; bltype := substr(rec.backlink, 1, 2); if bltype = ''PL'' then declare rec record; begin select into rec * from PLine where slotname = outer.rec.backlink; retval := ''Phone line '' || trim(rec.phonenumber); if rec.comment != '''' then retval := retval || '' (''; retval := retval || rec.comment; retval := retval || '')''; end if; return retval; end; end if; if bltype = ''WS'' then select into rec * from WSlot where slotname = rec.backlink; retval := trim(rec.slotname) || '' in room ''; retval := retval || trim(rec.roomno); retval := retval || '' -> ''; return retval || wslot_slotlink_view(rec.slotname); end if; return rec.backlink; end; ' language 'plpgsql'; -- ************************************************************ -- * Describe the front of a patchfield slot -- ************************************************************ create function pslot_slotlink_view(bpchar) returns text as ' declare psrec record; sltype char(2); retval text; begin select into psrec * from PSlot where slotname = $1; if not found then return ''''; end if; if psrec.slotlink = '''' then return ''-''; end if; sltype := substr(psrec.slotlink, 1, 2); if sltype = ''PS'' then retval := trim(psrec.slotlink) || '' -> ''; return retval || pslot_backlink_view(psrec.slotlink); end if; if sltype = ''HS'' then retval := comment from Hub H, HSlot HS where HS.slotname = psrec.slotlink and H.name = HS.hubname; retval := retval || '' slot ''; retval := retval || slotno::text from HSlot where slotname = psrec.slotlink; return retval; end if; return psrec.slotlink; end; ' language 'plpgsql'; -- ************************************************************ -- * Describe the front of a wall connector slot -- ************************************************************ create function wslot_slotlink_view(bpchar) returns text as ' declare rec record; sltype char(2); retval text; begin select into rec * from WSlot where slotname = $1; if not found then return ''''; end if; if rec.slotlink = '''' then return ''-''; end if; sltype := substr(rec.slotlink, 1, 2); if sltype = ''PH'' then select into rec * from PHone where slotname = rec.slotlink; retval := ''Phone '' || trim(rec.slotname); if rec.comment != '''' then retval := retval || '' (''; retval := retval || rec.comment; retval := retval || '')''; end if; return retval; end if; if sltype = ''IF'' then declare syrow System%RowType; ifrow IFace%ROWTYPE; begin select into ifrow * from IFace where slotname = rec.slotlink; select into syrow * from System where name = ifrow.sysname; retval := syrow.name || '' IF ''; retval := retval || ifrow.ifname; if syrow.comment != '''' then retval := retval || '' (''; retval := retval || syrow.comment; retval := retval || '')''; end if; return retval; end; end if; return rec.slotlink; end; ' language 'plpgsql'; -- ************************************************************ -- * View of a patchfield describing backside and patches -- ************************************************************ create view Pfield_v1 as select PF.pfname, PF.slotname, pslot_backlink_view(PF.slotname) as backside, pslot_slotlink_view(PF.slotname) as patch from PSlot PF; -- -- First we build the house - so we create the rooms -- insert into Room values ('001', 'Entrance'); insert into Room values ('002', 'Office'); insert into Room values ('003', 'Office'); insert into Room values ('004', 'Technical'); insert into Room values ('101', 'Office'); insert into Room values ('102', 'Conference'); insert into Room values ('103', 'Restroom'); insert into Room values ('104', 'Technical'); insert into Room values ('105', 'Office'); insert into Room values ('106', 'Office'); -- -- Second we install the wall connectors -- insert into WSlot values ('WS.001.1a', '001', '', ''); insert into WSlot values ('WS.001.1b', '001', '', ''); insert into WSlot values ('WS.001.2a', '001', '', ''); insert into WSlot values ('WS.001.2b', '001', '', ''); insert into WSlot values ('WS.001.3a', '001', '', ''); insert into WSlot values ('WS.001.3b', '001', '', ''); insert into WSlot values ('WS.002.1a', '002', '', ''); insert into WSlot values ('WS.002.1b', '002', '', ''); insert into WSlot values ('WS.002.2a', '002', '', ''); insert into WSlot values ('WS.002.2b', '002', '', ''); insert into WSlot values ('WS.002.3a', '002', '', ''); insert into WSlot values ('WS.002.3b', '002', '', ''); insert into WSlot values ('WS.003.1a', '003', '', ''); insert into WSlot values ('WS.003.1b', '003', '', ''); insert into WSlot values ('WS.003.2a', '003', '', ''); insert into WSlot values ('WS.003.2b', '003', '', ''); insert into WSlot values ('WS.003.3a', '003', '', ''); insert into WSlot values ('WS.003.3b', '003', '', ''); insert into WSlot values ('WS.101.1a', '101', '', ''); insert into WSlot values ('WS.101.1b', '101', '', ''); insert into WSlot values ('WS.101.2a', '101', '', ''); insert into WSlot values ('WS.101.2b', '101', '', ''); insert into WSlot values ('WS.101.3a', '101', '', ''); insert into WSlot values ('WS.101.3b', '101', '', ''); insert into WSlot values ('WS.102.1a', '102', '', ''); insert into WSlot values ('WS.102.1b', '102', '', ''); insert into WSlot values ('WS.102.2a', '102', '', ''); insert into WSlot values ('WS.102.2b', '102', '', ''); insert into WSlot values ('WS.102.3a', '102', '', ''); insert into WSlot values ('WS.102.3b', '102', '', ''); insert into WSlot values ('WS.105.1a', '105', '', ''); insert into WSlot values ('WS.105.1b', '105', '', ''); insert into WSlot values ('WS.105.2a', '105', '', ''); insert into WSlot values ('WS.105.2b', '105', '', ''); insert into WSlot values ('WS.105.3a', '105', '', ''); insert into WSlot values ('WS.105.3b', '105', '', ''); insert into WSlot values ('WS.106.1a', '106', '', ''); insert into WSlot values ('WS.106.1b', '106', '', ''); insert into WSlot values ('WS.106.2a', '106', '', ''); insert into WSlot values ('WS.106.2b', '106', '', ''); insert into WSlot values ('WS.106.3a', '106', '', ''); insert into WSlot values ('WS.106.3b', '106', '', ''); -- -- Now create the patch fields and their slots -- insert into PField values ('PF0_1', 'Wallslots basement'); -- -- The cables for these will be made later, so they are unconnected for now -- insert into PSlot values ('PS.base.a1', 'PF0_1', '', ''); insert into PSlot values ('PS.base.a2', 'PF0_1', '', ''); insert into PSlot values ('PS.base.a3', 'PF0_1', '', ''); insert into PSlot values ('PS.base.a4', 'PF0_1', '', ''); insert into PSlot values ('PS.base.a5', 'PF0_1', '', ''); insert into PSlot values ('PS.base.a6', 'PF0_1', '', ''); -- -- These are already wired to the wall connectors -- insert into PSlot values ('PS.base.b1', 'PF0_1', '', 'WS.002.1a'); insert into PSlot values ('PS.base.b2', 'PF0_1', '', 'WS.002.1b'); insert into PSlot values ('PS.base.b3', 'PF0_1', '', 'WS.002.2a'); insert into PSlot values ('PS.base.b4', 'PF0_1', '', 'WS.002.2b'); insert into PSlot values ('PS.base.b5', 'PF0_1', '', 'WS.002.3a'); insert into PSlot values ('PS.base.b6', 'PF0_1', '', 'WS.002.3b'); insert into PSlot values ('PS.base.c1', 'PF0_1', '', 'WS.003.1a'); insert into PSlot values ('PS.base.c2', 'PF0_1', '', 'WS.003.1b'); insert into PSlot values ('PS.base.c3', 'PF0_1', '', 'WS.003.2a'); insert into PSlot values ('PS.base.c4', 'PF0_1', '', 'WS.003.2b'); insert into PSlot values ('PS.base.c5', 'PF0_1', '', 'WS.003.3a'); insert into PSlot values ('PS.base.c6', 'PF0_1', '', 'WS.003.3b'); -- -- This patchfield will be renamed later into PF0_2 - so its -- slots references in pfname should follow -- insert into PField values ('PF0_X', 'Phonelines basement'); insert into PSlot values ('PS.base.ta1', 'PF0_X', '', ''); insert into PSlot values ('PS.base.ta2', 'PF0_X', '', ''); insert into PSlot values ('PS.base.ta3', 'PF0_X', '', ''); insert into PSlot values ('PS.base.ta4', 'PF0_X', '', ''); insert into PSlot values ('PS.base.ta5', 'PF0_X', '', ''); insert into PSlot values ('PS.base.ta6', 'PF0_X', '', ''); insert into PSlot values ('PS.base.tb1', 'PF0_X', '', ''); insert into PSlot values ('PS.base.tb2', 'PF0_X', '', ''); insert into PSlot values ('PS.base.tb3', 'PF0_X', '', ''); insert into PSlot values ('PS.base.tb4', 'PF0_X', '', ''); insert into PSlot values ('PS.base.tb5', 'PF0_X', '', ''); insert into PSlot values ('PS.base.tb6', 'PF0_X', '', ''); insert into PField values ('PF1_1', 'Wallslots 1st floor'); insert into PSlot values ('PS.1st.a1', 'PF1_1', '', 'WS.101.1a'); insert into PSlot values ('PS.1st.a2', 'PF1_1', '', 'WS.101.1b'); insert into PSlot values ('PS.1st.a3', 'PF1_1', '', 'WS.101.2a'); insert into PSlot values ('PS.1st.a4', 'PF1_1', '', 'WS.101.2b'); insert into PSlot values ('PS.1st.a5', 'PF1_1', '', 'WS.101.3a'); insert into PSlot values ('PS.1st.a6', 'PF1_1', '', 'WS.101.3b'); insert into PSlot values ('PS.1st.b1', 'PF1_1', '', 'WS.102.1a'); insert into PSlot values ('PS.1st.b2', 'PF1_1', '', 'WS.102.1b'); insert into PSlot values ('PS.1st.b3', 'PF1_1', '', 'WS.102.2a'); insert into PSlot values ('PS.1st.b4', 'PF1_1', '', 'WS.102.2b'); insert into PSlot values ('PS.1st.b5', 'PF1_1', '', 'WS.102.3a'); insert into PSlot values ('PS.1st.b6', 'PF1_1', '', 'WS.102.3b'); insert into PSlot values ('PS.1st.c1', 'PF1_1', '', 'WS.105.1a'); insert into PSlot values ('PS.1st.c2', 'PF1_1', '', 'WS.105.1b'); insert into PSlot values ('PS.1st.c3', 'PF1_1', '', 'WS.105.2a'); insert into PSlot values ('PS.1st.c4', 'PF1_1', '', 'WS.105.2b'); insert into PSlot values ('PS.1st.c5', 'PF1_1', '', 'WS.105.3a'); insert into PSlot values ('PS.1st.c6', 'PF1_1', '', 'WS.105.3b'); insert into PSlot values ('PS.1st.d1', 'PF1_1', '', 'WS.106.1a'); insert into PSlot values ('PS.1st.d2', 'PF1_1', '', 'WS.106.1b'); insert into PSlot values ('PS.1st.d3', 'PF1_1', '', 'WS.106.2a'); insert into PSlot values ('PS.1st.d4', 'PF1_1', '', 'WS.106.2b'); insert into PSlot values ('PS.1st.d5', 'PF1_1', '', 'WS.106.3a'); insert into PSlot values ('PS.1st.d6', 'PF1_1', '', 'WS.106.3b'); -- -- Now we wire the wall connectors 1a-2a in room 001 to the -- patchfield. In the second update we make an error, and -- correct it after -- update PSlot set backlink = 'WS.001.1a' where slotname = 'PS.base.a1'; update PSlot set backlink = 'WS.001.1b' where slotname = 'PS.base.a3'; select * from WSlot where roomno = '001' order by slotname; slotname | roomno | slotlink | backlink ----------------------+----------+----------------------+---------------------- WS.001.1a | 001 | | PS.base.a1 WS.001.1b | 001 | | PS.base.a3 WS.001.2a | 001 | | WS.001.2b | 001 | | WS.001.3a | 001 | | WS.001.3b | 001 | | (6 rows) select * from PSlot where slotname ~ 'PS.base.a' order by slotname; slotname | pfname | slotlink | backlink ----------------------+--------+----------------------+---------------------- PS.base.a1 | PF0_1 | | WS.001.1a PS.base.a2 | PF0_1 | | PS.base.a3 | PF0_1 | | WS.001.1b PS.base.a4 | PF0_1 | | PS.base.a5 | PF0_1 | | PS.base.a6 | PF0_1 | | (6 rows) update PSlot set backlink = 'WS.001.2a' where slotname = 'PS.base.a3'; select * from WSlot where roomno = '001' order by slotname; slotname | roomno | slotlink | backlink ----------------------+----------+----------------------+---------------------- WS.001.1a | 001 | | PS.base.a1 WS.001.1b | 001 | | WS.001.2a | 001 | | PS.base.a3 WS.001.2b | 001 | | WS.001.3a | 001 | | WS.001.3b | 001 | | (6 rows) select * from PSlot where slotname ~ 'PS.base.a' order by slotname; slotname | pfname | slotlink | backlink ----------------------+--------+----------------------+---------------------- PS.base.a1 | PF0_1 | | WS.001.1a PS.base.a2 | PF0_1 | | PS.base.a3 | PF0_1 | | WS.001.2a PS.base.a4 | PF0_1 | | PS.base.a5 | PF0_1 | | PS.base.a6 | PF0_1 | | (6 rows) update PSlot set backlink = 'WS.001.1b' where slotname = 'PS.base.a2'; select * from WSlot where roomno = '001' order by slotname; slotname | roomno | slotlink | backlink ----------------------+----------+----------------------+---------------------- WS.001.1a | 001 | | PS.base.a1 WS.001.1b | 001 | | PS.base.a2 WS.001.2a | 001 | | PS.base.a3 WS.001.2b | 001 | | WS.001.3a | 001 | | WS.001.3b | 001 | | (6 rows) select * from PSlot where slotname ~ 'PS.base.a' order by slotname; slotname | pfname | slotlink | backlink ----------------------+--------+----------------------+---------------------- PS.base.a1 | PF0_1 | | WS.001.1a PS.base.a2 | PF0_1 | | WS.001.1b PS.base.a3 | PF0_1 | | WS.001.2a PS.base.a4 | PF0_1 | | PS.base.a5 | PF0_1 | | PS.base.a6 | PF0_1 | | (6 rows) -- -- Same procedure for 2b-3b but this time updating the WSlot instead -- of the PSlot. Due to the triggers the result is the same: -- WSlot and corresponding PSlot point to each other. -- update WSlot set backlink = 'PS.base.a4' where slotname = 'WS.001.2b'; update WSlot set backlink = 'PS.base.a6' where slotname = 'WS.001.3a'; select * from WSlot where roomno = '001' order by slotname; slotname | roomno | slotlink | backlink ----------------------+----------+----------------------+---------------------- WS.001.1a | 001 | | PS.base.a1 WS.001.1b | 001 | | PS.base.a2 WS.001.2a | 001 | | PS.base.a3 WS.001.2b | 001 | | PS.base.a4 WS.001.3a | 001 | | PS.base.a6 WS.001.3b | 001 | | (6 rows) select * from PSlot where slotname ~ 'PS.base.a' order by slotname; slotname | pfname | slotlink | backlink ----------------------+--------+----------------------+---------------------- PS.base.a1 | PF0_1 | | WS.001.1a PS.base.a2 | PF0_1 | | WS.001.1b PS.base.a3 | PF0_1 | | WS.001.2a PS.base.a4 | PF0_1 | | WS.001.2b PS.base.a5 | PF0_1 | | PS.base.a6 | PF0_1 | | WS.001.3a (6 rows) update WSlot set backlink = 'PS.base.a6' where slotname = 'WS.001.3b'; select * from WSlot where roomno = '001' order by slotname; slotname | roomno | slotlink | backlink ----------------------+----------+----------------------+---------------------- WS.001.1a | 001 | | PS.base.a1 WS.001.1b | 001 | | PS.base.a2 WS.001.2a | 001 | | PS.base.a3 WS.001.2b | 001 | | PS.base.a4 WS.001.3a | 001 | | WS.001.3b | 001 | | PS.base.a6 (6 rows) select * from PSlot where slotname ~ 'PS.base.a' order by slotname; slotname | pfname | slotlink | backlink ----------------------+--------+----------------------+---------------------- PS.base.a1 | PF0_1 | | WS.001.1a PS.base.a2 | PF0_1 | | WS.001.1b PS.base.a3 | PF0_1 | | WS.001.2a PS.base.a4 | PF0_1 | | WS.001.2b PS.base.a5 | PF0_1 | | PS.base.a6 | PF0_1 | | WS.001.3b (6 rows) update WSlot set backlink = 'PS.base.a5' where slotname = 'WS.001.3a'; select * from WSlot where roomno = '001' order by slotname; slotname | roomno | slotlink | backlink ----------------------+----------+----------------------+---------------------- WS.001.1a | 001 | | PS.base.a1 WS.001.1b | 001 | | PS.base.a2 WS.001.2a | 001 | | PS.base.a3 WS.001.2b | 001 | | PS.base.a4 WS.001.3a | 001 | | PS.base.a5 WS.001.3b | 001 | | PS.base.a6 (6 rows) select * from PSlot where slotname ~ 'PS.base.a' order by slotname; slotname | pfname | slotlink | backlink ----------------------+--------+----------------------+---------------------- PS.base.a1 | PF0_1 | | WS.001.1a PS.base.a2 | PF0_1 | | WS.001.1b PS.base.a3 | PF0_1 | | WS.001.2a PS.base.a4 | PF0_1 | | WS.001.2b PS.base.a5 | PF0_1 | | WS.001.3a PS.base.a6 | PF0_1 | | WS.001.3b (6 rows) insert into PField values ('PF1_2', 'Phonelines 1st floor'); insert into PSlot values ('PS.1st.ta1', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.ta2', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.ta3', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.ta4', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.ta5', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.ta6', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.tb1', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.tb2', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.tb3', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.tb4', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.tb5', 'PF1_2', '', ''); insert into PSlot values ('PS.1st.tb6', 'PF1_2', '', ''); -- -- Fix the wrong name for patchfield PF0_2 -- update PField set name = 'PF0_2' where name = 'PF0_X'; select * from PSlot order by slotname; slotname | pfname | slotlink | backlink ----------------------+--------+----------------------+---------------------- PS.1st.a1 | PF1_1 | | WS.101.1a PS.1st.a2 | PF1_1 | | WS.101.1b PS.1st.a3 | PF1_1 | | WS.101.2a PS.1st.a4 | PF1_1 | | WS.101.2b PS.1st.a5 | PF1_1 | | WS.101.3a PS.1st.a6 | PF1_1 | | WS.101.3b PS.1st.b1 | PF1_1 | | WS.102.1a PS.1st.b2 | PF1_1 | | WS.102.1b PS.1st.b3 | PF1_1 | | WS.102.2a PS.1st.b4 | PF1_1 | | WS.102.2b PS.1st.b5 | PF1_1 | | WS.102.3a PS.1st.b6 | PF1_1 | | WS.102.3b PS.1st.c1 | PF1_1 | | WS.105.1a PS.1st.c2 | PF1_1 | | WS.105.1b PS.1st.c3 | PF1_1 | | WS.105.2a PS.1st.c4 | PF1_1 | | WS.105.2b PS.1st.c5 | PF1_1 | | WS.105.3a PS.1st.c6 | PF1_1 | | WS.105.3b PS.1st.d1 | PF1_1 | | WS.106.1a PS.1st.d2 | PF1_1 | | WS.106.1b PS.1st.d3 | PF1_1 | | WS.106.2a PS.1st.d4 | PF1_1 | | WS.106.2b PS.1st.d5 | PF1_1 | | WS.106.3a PS.1st.d6 | PF1_1 | | WS.106.3b PS.1st.ta1 | PF1_2 | | PS.1st.ta2 | PF1_2 | | PS.1st.ta3 | PF1_2 | | PS.1st.ta4 | PF1_2 | | PS.1st.ta5 | PF1_2 | | PS.1st.ta6 | PF1_2 | | PS.1st.tb1 | PF1_2 | | PS.1st.tb2 | PF1_2 | | PS.1st.tb3 | PF1_2 | | PS.1st.tb4 | PF1_2 | | PS.1st.tb5 | PF1_2 | | PS.1st.tb6 | PF1_2 | | PS.base.a1 | PF0_1 | | WS.001.1a PS.base.a2 | PF0_1 | | WS.001.1b PS.base.a3 | PF0_1 | | WS.001.2a PS.base.a4 | PF0_1 | | WS.001.2b PS.base.a5 | PF0_1 | | WS.001.3a PS.base.a6 | PF0_1 | | WS.001.3b PS.base.b1 | PF0_1 | | WS.002.1a PS.base.b2 | PF0_1 | | WS.002.1b PS.base.b3 | PF0_1 | | WS.002.2a PS.base.b4 | PF0_1 | | WS.002.2b PS.base.b5 | PF0_1 | | WS.002.3a PS.base.b6 | PF0_1 | | WS.002.3b PS.base.c1 | PF0_1 | | WS.003.1a PS.base.c2 | PF0_1 | | WS.003.1b PS.base.c3 | PF0_1 | | WS.003.2a PS.base.c4 | PF0_1 | | WS.003.2b PS.base.c5 | PF0_1 | | WS.003.3a PS.base.c6 | PF0_1 | | WS.003.3b PS.base.ta1 | PF0_2 | | PS.base.ta2 | PF0_2 | | PS.base.ta3 | PF0_2 | | PS.base.ta4 | PF0_2 | | PS.base.ta5 | PF0_2 | | PS.base.ta6 | PF0_2 | | PS.base.tb1 | PF0_2 | | PS.base.tb2 | PF0_2 | | PS.base.tb3 | PF0_2 | | PS.base.tb4 | PF0_2 | | PS.base.tb5 | PF0_2 | | PS.base.tb6 | PF0_2 | | (66 rows) select * from WSlot order by slotname; slotname | roomno | slotlink | backlink ----------------------+----------+----------------------+---------------------- WS.001.1a | 001 | | PS.base.a1 WS.001.1b | 001 | | PS.base.a2 WS.001.2a | 001 | | PS.base.a3 WS.001.2b | 001 | | PS.base.a4 WS.001.3a | 001 | | PS.base.a5 WS.001.3b | 001 | | PS.base.a6 WS.002.1a | 002 | | PS.base.b1 WS.002.1b | 002 | | PS.base.b2 WS.002.2a | 002 | | PS.base.b3 WS.002.2b | 002 | | PS.base.b4 WS.002.3a | 002 | | PS.base.b5 WS.002.3b | 002 | | PS.base.b6 WS.003.1a | 003 | | PS.base.c1 WS.003.1b | 003 | | PS.base.c2 WS.003.2a | 003 | | PS.base.c3 WS.003.2b | 003 | | PS.base.c4 WS.003.3a | 003 | | PS.base.c5 WS.003.3b | 003 | | PS.base.c6 WS.101.1a | 101 | | PS.1st.a1 WS.101.1b | 101 | | PS.1st.a2 WS.101.2a | 101 | | PS.1st.a3 WS.101.2b | 101 | | PS.1st.a4 WS.101.3a | 101 | | PS.1st.a5 WS.101.3b | 101 | | PS.1st.a6 WS.102.1a | 102 | | PS.1st.b1 WS.102.1b | 102 | | PS.1st.b2 WS.102.2a | 102 | | PS.1st.b3 WS.102.2b | 102 | | PS.1st.b4 WS.102.3a | 102 | | PS.1st.b5 WS.102.3b | 102 | | PS.1st.b6 WS.105.1a | 105 | | PS.1st.c1 WS.105.1b | 105 | | PS.1st.c2 WS.105.2a | 105 | | PS.1st.c3 WS.105.2b | 105 | | PS.1st.c4 WS.105.3a | 105 | | PS.1st.c5 WS.105.3b | 105 | | PS.1st.c6 WS.106.1a | 106 | | PS.1st.d1 WS.106.1b | 106 | | PS.1st.d2 WS.106.2a | 106 | | PS.1st.d3 WS.106.2b | 106 | | PS.1st.d4 WS.106.3a | 106 | | PS.1st.d5 WS.106.3b | 106 | | PS.1st.d6 (42 rows) -- -- Install the central phone system and create the phone numbers. -- They are weired on insert to the patchfields. Again the -- triggers automatically tell the PSlots to update their -- backlink field. -- insert into PLine values ('PL.001', '-0', 'Central call', 'PS.base.ta1'); insert into PLine values ('PL.002', '-101', '', 'PS.base.ta2'); insert into PLine values ('PL.003', '-102', '', 'PS.base.ta3'); insert into PLine values ('PL.004', '-103', '', 'PS.base.ta5'); insert into PLine values ('PL.005', '-104', '', 'PS.base.ta6'); insert into PLine values ('PL.006', '-106', '', 'PS.base.tb2'); insert into PLine values ('PL.007', '-108', '', 'PS.base.tb3'); insert into PLine values ('PL.008', '-109', '', 'PS.base.tb4'); insert into PLine values ('PL.009', '-121', '', 'PS.base.tb5'); insert into PLine values ('PL.010', '-122', '', 'PS.base.tb6'); insert into PLine values ('PL.015', '-134', '', 'PS.1st.ta1'); insert into PLine values ('PL.016', '-137', '', 'PS.1st.ta3'); insert into PLine values ('PL.017', '-139', '', 'PS.1st.ta4'); insert into PLine values ('PL.018', '-362', '', 'PS.1st.tb1'); insert into PLine values ('PL.019', '-363', '', 'PS.1st.tb2'); insert into PLine values ('PL.020', '-364', '', 'PS.1st.tb3'); insert into PLine values ('PL.021', '-365', '', 'PS.1st.tb5'); insert into PLine values ('PL.022', '-367', '', 'PS.1st.tb6'); insert into PLine values ('PL.028', '-501', 'Fax entrance', 'PS.base.ta2'); insert into PLine values ('PL.029', '-502', 'Fax 1st floor', 'PS.1st.ta1'); -- -- Buy some phones, plug them into the wall and patch the -- phone lines to the corresponding patchfield slots. -- insert into PHone values ('PH.hc001', 'Hicom standard', 'WS.001.1a'); update PSlot set slotlink = 'PS.base.ta1' where slotname = 'PS.base.a1'; insert into PHone values ('PH.hc002', 'Hicom standard', 'WS.002.1a'); update PSlot set slotlink = 'PS.base.ta5' where slotname = 'PS.base.b1'; insert into PHone values ('PH.hc003', 'Hicom standard', 'WS.002.2a'); update PSlot set slotlink = 'PS.base.tb2' where slotname = 'PS.base.b3'; insert into PHone values ('PH.fax001', 'Canon fax', 'WS.001.2a'); update PSlot set slotlink = 'PS.base.ta2' where slotname = 'PS.base.a3'; -- -- Install a hub at one of the patchfields, plug a computers -- ethernet interface into the wall and patch it to the hub. -- insert into Hub values ('base.hub1', 'Patchfield PF0_1 hub', 16); insert into System values ('orion', 'PC'); insert into IFace values ('IF', 'orion', 'eth0', 'WS.002.1b'); update PSlot set slotlink = 'HS.base.hub1.1' where slotname = 'PS.base.b2'; -- -- Now we take a look at the patchfield -- select * from PField_v1 where pfname = 'PF0_1' order by slotname; pfname | slotname | backside | patch --------+----------------------+----------------------------------------------------------+----------------------------------------------- PF0_1 | PS.base.a1 | WS.001.1a in room 001 -> Phone PH.hc001 (Hicom standard) | PS.base.ta1 -> Phone line -0 (Central call) PF0_1 | PS.base.a2 | WS.001.1b in room 001 -> - | - PF0_1 | PS.base.a3 | WS.001.2a in room 001 -> Phone PH.fax001 (Canon fax) | PS.base.ta2 -> Phone line -501 (Fax entrance) PF0_1 | PS.base.a4 | WS.001.2b in room 001 -> - | - PF0_1 | PS.base.a5 | WS.001.3a in room 001 -> - | - PF0_1 | PS.base.a6 | WS.001.3b in room 001 -> - | - PF0_1 | PS.base.b1 | WS.002.1a in room 002 -> Phone PH.hc002 (Hicom standard) | PS.base.ta5 -> Phone line -103 PF0_1 | PS.base.b2 | WS.002.1b in room 002 -> orion IF eth0 (PC) | Patchfield PF0_1 hub slot 1 PF0_1 | PS.base.b3 | WS.002.2a in room 002 -> Phone PH.hc003 (Hicom standard) | PS.base.tb2 -> Phone line -106 PF0_1 | PS.base.b4 | WS.002.2b in room 002 -> - | - PF0_1 | PS.base.b5 | WS.002.3a in room 002 -> - | - PF0_1 | PS.base.b6 | WS.002.3b in room 002 -> - | - PF0_1 | PS.base.c1 | WS.003.1a in room 003 -> - | - PF0_1 | PS.base.c2 | WS.003.1b in room 003 -> - | - PF0_1 | PS.base.c3 | WS.003.2a in room 003 -> - | - PF0_1 | PS.base.c4 | WS.003.2b in room 003 -> - | - PF0_1 | PS.base.c5 | WS.003.3a in room 003 -> - | - PF0_1 | PS.base.c6 | WS.003.3b in room 003 -> - | - (18 rows) select * from PField_v1 where pfname = 'PF0_2' order by slotname; pfname | slotname | backside | patch --------+----------------------+--------------------------------+------------------------------------------------------------------------ PF0_2 | PS.base.ta1 | Phone line -0 (Central call) | PS.base.a1 -> WS.001.1a in room 001 -> Phone PH.hc001 (Hicom standard) PF0_2 | PS.base.ta2 | Phone line -501 (Fax entrance) | PS.base.a3 -> WS.001.2a in room 001 -> Phone PH.fax001 (Canon fax) PF0_2 | PS.base.ta3 | Phone line -102 | - PF0_2 | PS.base.ta4 | - | - PF0_2 | PS.base.ta5 | Phone line -103 | PS.base.b1 -> WS.002.1a in room 002 -> Phone PH.hc002 (Hicom standard) PF0_2 | PS.base.ta6 | Phone line -104 | - PF0_2 | PS.base.tb1 | - | - PF0_2 | PS.base.tb2 | Phone line -106 | PS.base.b3 -> WS.002.2a in room 002 -> Phone PH.hc003 (Hicom standard) PF0_2 | PS.base.tb3 | Phone line -108 | - PF0_2 | PS.base.tb4 | Phone line -109 | - PF0_2 | PS.base.tb5 | Phone line -121 | - PF0_2 | PS.base.tb6 | Phone line -122 | - (12 rows) -- -- Finally we want errors -- insert into PField values ('PF1_1', 'should fail due to unique index'); ERROR: duplicate key violates unique constraint "pfield_name" update PSlot set backlink = 'WS.not.there' where slotname = 'PS.base.a1'; ERROR: WS.not.there does not exist CONTEXT: PL/pgSQL function "tg_backlink_a" line 16 at assignment update PSlot set backlink = 'XX.illegal' where slotname = 'PS.base.a1'; ERROR: illegal backlink beginning with XX CONTEXT: PL/pgSQL function "tg_backlink_a" line 16 at assignment update PSlot set slotlink = 'PS.not.there' where slotname = 'PS.base.a1'; ERROR: PS.not.there does not exist CONTEXT: PL/pgSQL function "tg_slotlink_a" line 16 at assignment update PSlot set slotlink = 'XX.illegal' where slotname = 'PS.base.a1'; ERROR: illegal slotlink beginning with XX CONTEXT: PL/pgSQL function "tg_slotlink_a" line 16 at assignment insert into HSlot values ('HS', 'base.hub1', 1, ''); ERROR: duplicate key violates unique constraint "hslot_name" insert into HSlot values ('HS', 'base.hub1', 20, ''); ERROR: no manual manipulation of HSlot delete from HSlot; ERROR: no manual manipulation of HSlot insert into IFace values ('IF', 'notthere', 'eth0', ''); ERROR: system "notthere" does not exist insert into IFace values ('IF', 'orion', 'ethernet_interface_name_too_long', ''); ERROR: IFace slotname "IF.orion.ethernet_interface_name_too_long" too long (20 char max) -- -- The following tests are unrelated to the scenario outlined above; -- they merely exercise specific parts of PL/PgSQL -- -- -- Test recursion, per bug report 7-Sep-01 -- CREATE FUNCTION recursion_test(int,int) RETURNS text AS ' DECLARE rslt text; BEGIN IF $1 <= 0 THEN rslt = CAST($2 AS TEXT); ELSE rslt = CAST($1 AS TEXT) || '','' || recursion_test($1 - 1, $2); END IF; RETURN rslt; END;' LANGUAGE 'plpgsql'; SELECT recursion_test(4,3); recursion_test ---------------- 4,3,2,1,3 (1 row) -- -- Test the FOUND magic variable -- CREATE TABLE found_test_tbl (a int); create function test_found() returns boolean as ' declare begin insert into found_test_tbl values (1); if FOUND then insert into found_test_tbl values (2); end if; update found_test_tbl set a = 100 where a = 1; if FOUND then insert into found_test_tbl values (3); end if; delete from found_test_tbl where a = 9999; -- matches no rows if not FOUND then insert into found_test_tbl values (4); end if; for i in 1 .. 10 loop -- no need to do anything end loop; if FOUND then insert into found_test_tbl values (5); end if; -- never executes the loop for i in 2 .. 1 loop -- no need to do anything end loop; if not FOUND then insert into found_test_tbl values (6); end if; return true; end;' language 'plpgsql'; select test_found(); test_found ------------ t (1 row) select * from found_test_tbl; a ----- 2 100 3 4 5 6 (6 rows) -- -- Test set-returning functions for PL/pgSQL -- create function test_table_func_rec() returns setof found_test_tbl as ' DECLARE rec RECORD; BEGIN FOR rec IN select * from found_test_tbl LOOP RETURN NEXT rec; END LOOP; RETURN; END;' language 'plpgsql'; select * from test_table_func_rec(); a ----- 2 100 3 4 5 6 (6 rows) create function test_table_func_row() returns setof found_test_tbl as ' DECLARE row found_test_tbl%ROWTYPE; BEGIN FOR row IN select * from found_test_tbl LOOP RETURN NEXT row; END LOOP; RETURN; END;' language 'plpgsql'; select * from test_table_func_row(); a ----- 2 100 3 4 5 6 (6 rows) create function test_ret_set_scalar(int,int) returns setof int as ' DECLARE i int; BEGIN FOR i IN $1 .. $2 LOOP RETURN NEXT i + 1; END LOOP; RETURN; END;' language 'plpgsql'; select * from test_ret_set_scalar(1,10); test_ret_set_scalar --------------------- 2 3 4 5 6 7 8 9 10 11 (10 rows) create function test_ret_set_rec_dyn(int) returns setof record as ' DECLARE retval RECORD; BEGIN IF $1 > 10 THEN SELECT INTO retval 5, 10, 15; RETURN NEXT retval; RETURN NEXT retval; ELSE SELECT INTO retval 50, 5::numeric, ''xxx''::text; RETURN NEXT retval; RETURN NEXT retval; END IF; RETURN; END;' language 'plpgsql'; SELECT * FROM test_ret_set_rec_dyn(1500) AS (a int, b int, c int); a | b | c ---+----+---- 5 | 10 | 15 5 | 10 | 15 (2 rows) SELECT * FROM test_ret_set_rec_dyn(5) AS (a int, b numeric, c text); a | b | c ----+---+----- 50 | 5 | xxx 50 | 5 | xxx (2 rows) create function test_ret_rec_dyn(int) returns record as ' DECLARE retval RECORD; BEGIN IF $1 > 10 THEN SELECT INTO retval 5, 10, 15; RETURN retval; ELSE SELECT INTO retval 50, 5::numeric, ''xxx''::text; RETURN retval; END IF; END;' language 'plpgsql'; SELECT * FROM test_ret_rec_dyn(1500) AS (a int, b int, c int); a | b | c ---+----+---- 5 | 10 | 15 (1 row) SELECT * FROM test_ret_rec_dyn(5) AS (a int, b numeric, c text); a | b | c ----+---+----- 50 | 5 | xxx (1 row) -- -- test PERFORM -- create table perform_test ( a INT, b INT ); create function simple_func(int) returns boolean as ' BEGIN IF $1 < 20 THEN INSERT INTO perform_test VALUES ($1, $1 + 10); RETURN TRUE; ELSE RETURN FALSE; END IF; END;' language 'plpgsql'; create function perform_test_func() returns void as ' BEGIN IF FOUND then INSERT INTO perform_test VALUES (100, 100); END IF; PERFORM simple_func(5); IF FOUND then INSERT INTO perform_test VALUES (100, 100); END IF; PERFORM simple_func(50); IF FOUND then INSERT INTO perform_test VALUES (100, 100); END IF; RETURN; END;' language 'plpgsql'; SELECT perform_test_func(); perform_test_func ------------------- (1 row) SELECT * FROM perform_test; a | b -----+----- 5 | 15 100 | 100 100 | 100 (3 rows) drop table perform_test; -- -- Test error trapping -- create function trap_zero_divide(int) returns int as $$ declare x int; sx smallint; begin begin -- start a subtransaction raise notice 'should see this'; x := 100 / $1; raise notice 'should see this only if % <> 0', $1; sx := $1; raise notice 'should see this only if % fits in smallint', $1; if $1 < 0 then raise exception '% is less than zero', $1; end if; exception when division_by_zero then raise notice 'caught division_by_zero'; x := -1; when NUMERIC_VALUE_OUT_OF_RANGE then raise notice 'caught numeric_value_out_of_range'; x := -2; end; return x; end$$ language plpgsql; select trap_zero_divide(50); NOTICE: should see this NOTICE: should see this only if 50 <> 0 NOTICE: should see this only if 50 fits in smallint trap_zero_divide ------------------ 2 (1 row) select trap_zero_divide(0); NOTICE: should see this NOTICE: caught division_by_zero trap_zero_divide ------------------ -1 (1 row) select trap_zero_divide(100000); NOTICE: should see this NOTICE: should see this only if 100000 <> 0 NOTICE: caught numeric_value_out_of_range trap_zero_divide ------------------ -2 (1 row) select trap_zero_divide(-100); NOTICE: should see this NOTICE: should see this only if -100 <> 0 NOTICE: should see this only if -100 fits in smallint ERROR: -100 is less than zero create function trap_matching_test(int) returns int as $$ declare x int; sx smallint; y int; begin begin -- start a subtransaction x := 100 / $1; sx := $1; select into y unique1 from tenk1 where unique2 = (select unique2 from tenk1 b where ten = $1); exception when data_exception then -- category match raise notice 'caught data_exception'; x := -1; when NUMERIC_VALUE_OUT_OF_RANGE OR CARDINALITY_VIOLATION then raise notice 'caught numeric_value_out_of_range or cardinality_violation'; x := -2; end; return x; end$$ language plpgsql; select trap_matching_test(50); trap_matching_test -------------------- 2 (1 row) select trap_matching_test(0); NOTICE: caught data_exception trap_matching_test -------------------- -1 (1 row) select trap_matching_test(100000); NOTICE: caught data_exception trap_matching_test -------------------- -1 (1 row) select trap_matching_test(1); NOTICE: caught numeric_value_out_of_range or cardinality_violation trap_matching_test -------------------- -2 (1 row) create temp table foo (f1 int); create function blockme() returns int as $$ declare x int; begin x := 1; insert into foo values(x); begin x := x + 1; insert into foo values(x); -- we assume this will take longer than 1 second: select count(*) into x from tenk1 a, tenk1 b, tenk1 c; exception when others then raise notice 'caught others?'; return -1; when query_canceled then raise notice 'nyeah nyeah, can''t stop me'; x := x * 10; end; insert into foo values(x); return x; end$$ language plpgsql; set statement_timeout to 1000; select blockme(); NOTICE: nyeah nyeah, can't stop me blockme --------- 20 (1 row) reset statement_timeout; select * from foo; f1 ---- 1 20 (2 rows) -- -- test foreign key error trapping -- create temp table master(f1 int primary key); NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "master_pkey" for table "master" create temp table slave(f1 int references master deferrable); insert into master values(1); insert into slave values(1); insert into slave values(2); -- fails ERROR: insert or update on table "slave" violates foreign key constraint "slave_f1_fkey" DETAIL: Key (f1)=(2) is not present in table "master". create function trap_foreign_key(int) returns int as $$ begin begin -- start a subtransaction insert into slave values($1); exception when foreign_key_violation then raise notice 'caught foreign_key_violation'; return 0; end; return 1; end$$ language plpgsql; create function trap_foreign_key_2() returns int as $$ begin begin -- start a subtransaction set constraints all immediate; exception when foreign_key_violation then raise notice 'caught foreign_key_violation'; return 0; end; return 1; end$$ language plpgsql; select trap_foreign_key(1); trap_foreign_key ------------------ 1 (1 row) select trap_foreign_key(2); -- detects FK violation NOTICE: caught foreign_key_violation trap_foreign_key ------------------ 0 (1 row) begin; set constraints all deferred; select trap_foreign_key(2); -- should not detect FK violation trap_foreign_key ------------------ 1 (1 row) savepoint x; set constraints all immediate; -- fails ERROR: insert or update on table "slave" violates foreign key constraint "slave_f1_fkey" DETAIL: Key (f1)=(2) is not present in table "master". rollback to x; select trap_foreign_key_2(); -- detects FK violation NOTICE: caught foreign_key_violation trap_foreign_key_2 -------------------- 0 (1 row) commit; -- still fails ERROR: insert or update on table "slave" violates foreign key constraint "slave_f1_fkey" DETAIL: Key (f1)=(2) is not present in table "master". drop function trap_foreign_key(int); drop function trap_foreign_key_2();