Prevent OU loops at DB level
authorThomas Berezansky <tsbere@mvlc.org>
Thu, 16 Jun 2011 02:03:38 +0000 (22:03 -0400)
committerMike Rylander <mrylander@gmail.com>
Sat, 16 Jul 2011 14:05:50 +0000 (10:05 -0400)
Database trigger to prevent actor.org_unit from being parent of self

Actually detects any loops, even those above the current point

Signed-off-by: Thomas Berezansky <tsbere@mvlc.org>
Signed-off-by: Mike Rylander <mrylander@gmail.com>
Open-ILS/src/sql/Pg/005.schema.actors.sql

index 058387c..75b379e 100644 (file)
@@ -288,6 +288,40 @@ CREATE INDEX actor_org_unit_billing_address_idx ON actor.org_unit (billing_addre
 CREATE INDEX actor_org_unit_mailing_address_idx ON actor.org_unit (mailing_address);
 CREATE INDEX actor_org_unit_holds_address_idx ON actor.org_unit (holds_address);
 
+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 ();
+
 CREATE TABLE actor.org_lasso (
     id      SERIAL  PRIMARY KEY,
     name       TEXT    UNIQUE