From: Mike Rylander Date: Sat, 16 Jul 2011 14:08:03 +0000 (-0400) Subject: Stamping upgrade script for "Prevent OU loops at DB level" X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=7f25c35f3242baef8306577ebe13785f2b1b472d;p=evergreen%2Fmasslnc.git Stamping upgrade script for "Prevent OU loops at DB level" Signed-off-by: Mike Rylander --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index df635b83a8..5adb85517f 100644 --- a/Open-ILS/src/sql/Pg/002.schema.config.sql +++ b/Open-ILS/src/sql/Pg/002.schema.config.sql @@ -86,7 +86,7 @@ CREATE TRIGGER no_overlapping_deps BEFORE INSERT OR UPDATE ON config.db_patch_dependencies FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates'); -INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0579', :eg_version); -- tsbere via miker +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0580', :eg_version); -- tsbere via miker CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/upgrade/0580.schema.aou_parent_protec.sql b/Open-ILS/src/sql/Pg/upgrade/0580.schema.aou_parent_protec.sql new file mode 100644 index 0000000000..1c86c0aa02 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/0580.schema.aou_parent_protec.sql @@ -0,0 +1,45 @@ +-- Evergreen DB patch 0580.schema.aou_parent_protec.sql +-- +-- +BEGIN; + + +-- check whether patch can be applied +SELECT evergreen.upgrade_deps_block_check('0580', :eg_version); + +CREATE OR REPLACE FUNCTION actor.org_unit_parent_protect () RETURNS TRIGGER AS $$ + DECLARE + current_aou actor.org_unit%ROWTYPE; + seen_ous INT[]; + depth_count INT; + BEGIN + current_aou := NEW; + depth_count := 0; + seen_ous := ARRAY[NEW.id]; + IF TG_OP = 'INSERT' OR NEW.parent_ou IS DISTINCT FROM OLD.parent_ou THEN + LOOP + IF current_aou.parent_ou IS NULL THEN -- Top of the org tree? + RETURN NEW; -- No loop. Carry on. + END IF; + IF current_aou.parent_ou = ANY(seen_ous) THEN -- Parent is one we have seen? + RAISE 'OU LOOP: Saw % twice', current_aou.parent_ou; -- LOOP! ABORT! + END IF; + -- Get the next one! + SELECT INTO current_aou * FROM actor.org_unit WHERE id = current_aou.parent_ou; + seen_ous := seen_ous || current_aou.id; + depth_count := depth_count + 1; + IF depth_count = 100 THEN + RAISE 'OU CHECK TOO DEEP'; + END IF; + END LOOP; + END IF; + RETURN NEW; + END; +$$ LANGUAGE PLPGSQL; + +CREATE TRIGGER actor_org_unit_parent_protect_trigger + BEFORE INSERT OR UPDATE ON actor.org_unit FOR EACH ROW + EXECUTE PROCEDURE actor.org_unit_parent_protect (); + + +COMMIT; diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.aou_parent_protect.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.aou_parent_protect.sql deleted file mode 100644 index 589aa973f6..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/XXXX.aou_parent_protect.sql +++ /dev/null @@ -1,33 +0,0 @@ -CREATE OR REPLACE FUNCTION actor.org_unit_parent_protect () RETURNS TRIGGER AS $$ - DECLARE - current_aou actor.org_unit%ROWTYPE; - seen_ous INT[]; - depth_count INT; - BEGIN - current_aou := NEW; - depth_count := 0; - seen_ous := ARRAY[NEW.id]; - IF TG_OP = 'INSERT' OR NEW.parent_ou IS DISTINCT FROM OLD.parent_ou THEN - LOOP - IF current_aou.parent_ou IS NULL THEN -- Top of the org tree? - RETURN NEW; -- No loop. Carry on. - END IF; - IF current_aou.parent_ou = ANY(seen_ous) THEN -- Parent is one we have seen? - RAISE 'OU LOOP: Saw % twice', current_aou.parent_ou; -- LOOP! ABORT! - END IF; - -- Get the next one! - SELECT INTO current_aou * FROM actor.org_unit WHERE id = current_aou.parent_ou; - seen_ous := seen_ous || current_aou.id; - depth_count := depth_count + 1; - IF depth_count = 100 THEN - RAISE 'OU CHECK TOO DEEP'; - END IF; - END LOOP; - END IF; - RETURN NEW; - END; -$$ LANGUAGE PLPGSQL; - -CREATE TRIGGER actor_org_unit_parent_protect_trigger - BEFORE INSERT OR UPDATE ON actor.org_unit FOR EACH ROW - EXECUTE PROCEDURE actor.org_unit_parent_protect ();