diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql index e882b2c8548e1844cbf52a62ed7d211a40f43a98..0cefd81819af6562b35efb468da71e8ffc2bb361 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql @@ -11,6 +11,7 @@ $BODY$ DECLARE claim_tentative_status_id int := 0; --beware: hard coded instead of lookup for performance claim_claimed_status_id int := 1; --beware: hard coded instead of lookup for performance + claim_conflict_status_id int := 2; --beware: hard coded instead of lookup for performance task_approved_status_id int := 300; --beware: hard coded instead of lookup for performance task_conflict_status_id int := 335; --beware: hard coded instead of lookup for performance task_prescheduled_status_id int := 350; --beware: hard coded instead of lookup for performance @@ -19,14 +20,20 @@ DECLARE task_aborted_status_id int := 1100; --beware: hard coded instead of lookup for performance BEGIN IF NEW.status_id <> OLD.status_id THEN - RAISE NOTICE 'on_task_updated: updating task id=% from status % to %', NEW.id, OLD.status_id, NEW.status_id; + IF OLD.status_id = task_conflict_status_id AND NEW.status_id <> task_conflict_status_id THEN + -- bookkeeping, cleanup task_status_before_conlict table for this task + DELETE FROM resource_allocation.task_status_before_conlict WHERE task_id = NEW.id; + END IF; + IF NEW.status_id = task_scheduled_status_id AND OLD.status_id <> task_prescheduled_status_id THEN -- tasks can only be scheduled from the prescheduled state RAISE EXCEPTION 'Cannot update task status from % to %', OLD.status_id, NEW.status_id; END IF; - IF OLD.status_id = task_conflict_status_id AND NEW.status_id <> task_approved_status_id THEN - RAISE EXCEPTION 'When a task has the conflict status it can has to be set to approved status first by making sure all its claims have no conflict status anymore.'; + IF OLD.status_id = task_conflict_status_id AND + NEW.status_id <> task_approved_status_id AND + EXISTS (SELECT id FROM resource_allocation.resource_claim rc WHERE rc.task_id = NEW.id AND rc.status_id = claim_conflict_status_id) THEN + RAISE EXCEPTION 'When a task has the conflict status and if has claims in conflict, it has to be set to approved status first by making sure all its claims have no conflict status anymore.'; END IF; IF NEW.status_id = task_approved_status_id OR NEW.status_id = task_conflict_status_id THEN @@ -55,7 +62,7 @@ $BODY$ ALTER FUNCTION resource_allocation.on_task_updated() OWNER TO resourceassignment; COMMENT ON FUNCTION resource_allocation.on_task_updated() - IS 'function which is called by task table update trigger, which updates all the tasks resource claims to tentative state.'; + IS 'function which is called by task table update trigger.'; DROP TRIGGER IF EXISTS T_on_task_updated ON resource_allocation.task CASCADE; CREATE TRIGGER T_on_task_updated @@ -63,8 +70,38 @@ CREATE TRIGGER T_on_task_updated ON resource_allocation.task FOR EACH ROW EXECUTE PROCEDURE resource_allocation.on_task_updated(); -COMMENT ON TRIGGER T_on_task_updated ON resource_allocation.task - IS 'task table update trigger, calls the resource_allocation.on_task_updated() function.'; + +--------------------------------------------------------------------------------------------------------------------- + +CREATE OR REPLACE FUNCTION resource_allocation.on_before_task_status_updated() + RETURNS trigger AS +$BODY$ +DECLARE + task_approved_status_id int := 300; --beware: hard coded instead of lookup for performance + task_conflict_status_id int := 335; --beware: hard coded instead of lookup for performance + task_prescheduled_status_id int := 350; --beware: hard coded instead of lookup for performance +BEGIN + IF NEW.status_id = task_conflict_status_id AND + (OLD.status_id = task_approved_status_id OR OLD.status_id = task_prescheduled_status_id) THEN + -- bookkeeping, log previous status_ud in task_status_before_conlict table for this task + INSERT INTO resource_allocation.task_status_before_conlict (task_id, status_id) VALUES (OLD.id, OLD.status_id); + END IF; +RETURN NEW; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +ALTER FUNCTION resource_allocation.on_before_task_status_updated() + OWNER TO resourceassignment; +COMMENT ON FUNCTION resource_allocation.on_before_task_status_updated() + IS 'function which is called by T_on_before_task_status_updated trigger.'; + +DROP TRIGGER IF EXISTS T_on_before_task_status_updated ON resource_allocation.task CASCADE; +CREATE TRIGGER T_on_before_task_status_updated + BEFORE UPDATE OF status_id + ON resource_allocation.task + FOR EACH ROW + EXECUTE PROCEDURE resource_allocation.on_before_task_status_updated(); --------------------------------------------------------------------------------------------------------------------- @@ -819,7 +856,6 @@ BEGIN IF TG_OP = 'INSERT' OR (TG_OP = 'UPDATE' AND (OLD.status_id <> NEW.status_id)) THEN IF NEW.status_id = claim_conflict_status_id THEN --if claim status went to conflict, then set the task status to conflict as well - RAISE NOTICE 'after_claim_insertupdatedelete: updating task id=% to conflict status % because there are claims in conflict for this task', NEW.task_id, task_conflict_status_id; UPDATE resource_allocation.task SET status_id=task_conflict_status_id WHERE id=NEW.task_id AND status_id <> task_conflict_status_id; ELSIF NEW.status_id = claim_tentative_status_id THEN IF NOT EXISTS (SELECT id FROM resource_allocation.resource_claim @@ -829,11 +865,10 @@ BEGIN IF NOT EXISTS (SELECT id FROM resource_allocation.task WHERE id = NEW.task_id AND status_id = task_approved_status_id) THEN - RAISE NOTICE 'after_claim_insertupdatedelete: updating task id=% to approved status % because there are no more claims in conflict for this task', NEW.task_id, task_approved_status_id; -- update tasks which were in conflict, but which are not anymore due this claim-update to the approved status - UPDATE resource_allocation.task SET status_id=task_approved_status_id + UPDATE resource_allocation.task + SET status_id=COALESCE((SELECT status_id from resource_allocation.task_status_before_conlict WHERE task_id=NEW.task_id), task_approved_status_id) WHERE id=NEW.task_id AND status_id = task_conflict_status_id; - RAISE NOTICE 'after_claim_insertupdatedelete: updated task id=% to approved status % because there are no more claims in conflict for this task', NEW.task_id, task_approved_status_id; END IF; END IF; END IF; diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql index a82dfe3779bc0bd495cdef58acc7d4601daeb4ca..489b3f6a4d48126a96be4986a18161f92c1f56a5 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql @@ -197,6 +197,15 @@ CREATE INDEX task_status_id_idx CREATE INDEX task_type_id_idx ON resource_allocation.task (type_id); + +CREATE TABLE resource_allocation.task_status_before_conlict ( + task_id integer NOT NULL REFERENCES resource_allocation.task(id) ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE, + status_id integer NOT NULL REFERENCES resource_allocation.task_status ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE, + PRIMARY KEY (task_id) +) WITH (OIDS=FALSE); +ALTER TABLE resource_allocation.task_status_before_conlict + OWNER TO resourceassignment; + CREATE TABLE resource_allocation.task_predecessor ( id serial NOT NULL, task_id integer NOT NULL REFERENCES resource_allocation.task(id) ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE,