From e302ec8c6913f5bda3f36d4aef0e540239a392b4 Mon Sep 17 00:00:00 2001 From: Jorrit Schaap <schaap@astron.nl> Date: Fri, 8 Apr 2016 10:35:14 +0000 Subject: [PATCH] Task #9309: added conflict_reasons, task and resource_claim relations. Added initial storage and bandwith set of conflict reasons. Added triggers to ensure db consistancy on task and resource_claim conflict status --- .../sql/add_resource_allocation_statics.sql | 10 ++ .../sql/add_triggers.sql | 115 ++++++++++++++++++ .../sql/create_database.sql | 29 +++++ 3 files changed, 154 insertions(+) diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_resource_allocation_statics.sql b/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_resource_allocation_statics.sql index 6380fe9e26b..4717ae01028 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_resource_allocation_statics.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_resource_allocation_statics.sql @@ -9,4 +9,14 @@ INSERT INTO resource_allocation.task_type VALUES (0, 'observation'),(1, 'pipelin INSERT INTO resource_allocation.resource_claim_status VALUES (0, 'claimed'), (1, 'allocated'), (2, 'conflict'); INSERT INTO resource_allocation.resource_claim_property_type VALUES (0, 'nr_of_is_files'),(1, 'nr_of_cs_files'),(2, 'nr_of_uv_files'),(3, 'nr_of_im_files'),(4, 'nr_of_img_files'),(5, 'nr_of_pulp_files'),(6, 'nr_of_cs_stokes'),(7, 'nr_of_is_stokes'),(8, 'is_file_size'),(9, 'cs_file_size'),(10, 'uv_file_size'),(11, 'im_file_size'),(12, 'img_file_size'),(13, 'nr_of_pulp_files'),(14, 'nr_of_tabs'); INSERT INTO resource_allocation.config VALUES (0, 'max_fill_percentage_cep4', '85.00'), (1, 'claim_timeout', '172800'); -- Just some values 172800 is two days in seconds +INSERT INTO resource_allocation.conflict_reason +VALUES +(1, 'Not enough total free storage space'), +(2, 'Storage node inactive'), +(3, 'Number of storage nodes available less than minimum required'), +(4, 'No suitable storage options found'), +(5, 'No storage nodes available'), +(6, 'Not enough available storage nodes for required bandwidth'), +(7, 'Network bandwidth to storage node too high'), +(8, 'Bandwidth required for single file too high'); COMMIT; diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_triggers.sql b/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_triggers.sql index 09548d7168a..d8df06ab623 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_triggers.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_triggers.sql @@ -28,3 +28,118 @@ CREATE TRIGGER trigger_delete_resource_claims_for_approved_task COMMENT ON TRIGGER trigger_delete_resource_claims_for_approved_task ON resource_allocation.task IS 'task table update trigger, calls the resource_allocation.delete_resource_claims_for_approved_task() function.'; +--------------------------------------------------------------------------------------------------------------------- + +DROP TRIGGER IF EXISTS trigger_delete_conflict_reasons_after_resource_claim_update ON resource_allocation.resource_claim CASCADE; +DROP FUNCTION IF EXISTS resource_allocation.delete_conflict_reasons_after_resource_claim_update(); + +CREATE OR REPLACE FUNCTION resource_allocation.delete_conflict_reasons_after_resource_claim_update() + RETURNS trigger AS +$BODY$ +BEGIN + IF OLD.status_id = 2 AND NEW.status_id <> 2 THEN --new status is not conflict + DELETE FROM resource_allocation.resource_claim_conflict_reason rccr WHERE rccr.resource_claim_id = NEW.id; + END IF; +RETURN NEW; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +ALTER FUNCTION resource_allocation.delete_conflict_reasons_after_resource_claim_update() + OWNER TO resourceassignment; +COMMENT ON FUNCTION resource_allocation.delete_conflict_reasons_after_resource_claim_update() + IS 'function which is called by resource_claim table update trigger, which deletes resource_claim_conflict_reasons when the claim status is updated to !conflict.'; + +CREATE TRIGGER trigger_delete_conflict_reasons_after_resource_claim_update + AFTER UPDATE + ON resource_allocation.resource_claim + FOR EACH ROW + EXECUTE PROCEDURE resource_allocation.delete_conflict_reasons_after_resource_claim_update(); + +--------------------------------------------------------------------------------------------------------------------- + +DROP TRIGGER IF EXISTS trigger_before_insert_conflict_reason_do_resource_claim_status_check ON resource_allocation.resource_claim_conflict_reason CASCADE; +DROP FUNCTION IF EXISTS resource_allocation.before_insert_conflict_reason_do_resource_claim_status_check(); + +CREATE OR REPLACE FUNCTION resource_allocation.before_insert_conflict_reason_do_resource_claim_status_check() + RETURNS trigger AS +$BODY$ +BEGIN + -- check if referred resource_claim is in conflict status, else raise + IF (SELECT COUNT(id) FROM resource_allocation.resource_claim rc WHERE rc.id = NEW.resource_claim_id AND rc.status_id = 2) = 0 THEN + RAISE EXCEPTION 'resource_claim has no conflict status'; + END IF; +RETURN NEW; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +ALTER FUNCTION resource_allocation.before_insert_conflict_reason_do_resource_claim_status_check() + OWNER TO resourceassignment; +COMMENT ON FUNCTION resource_allocation.before_insert_conflict_reason_do_resource_claim_status_check() + IS 'check if referred resource_claim is in conflict status, else raise'; + +CREATE TRIGGER trigger_before_insert_conflict_reason_do_resource_claim_status_check + BEFORE INSERT + ON resource_allocation.resource_claim_conflict_reason + FOR EACH ROW + EXECUTE PROCEDURE resource_allocation.before_insert_conflict_reason_do_resource_claim_status_check(); + +--------------------------------------------------------------------------------------------------------------------- + +DROP TRIGGER IF EXISTS trigger_delete_conflict_reasons_after_task_update ON resource_allocation.task CASCADE; +DROP FUNCTION IF EXISTS resource_allocation.delete_conflict_reasons_after_task_update(); + +CREATE OR REPLACE FUNCTION resource_allocation.delete_conflict_reasons_after_task_update() + RETURNS trigger AS +$BODY$ +BEGIN + IF OLD.status_id = 335 AND NEW.status_id <> 335 THEN --new status is not conflict + DELETE FROM resource_allocation.task_conflict_reason tcr WHERE tcr.task_id = NEW.id; + END IF; +RETURN NEW; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +ALTER FUNCTION resource_allocation.delete_conflict_reasons_after_task_update() + OWNER TO resourceassignment; +COMMENT ON FUNCTION resource_allocation.delete_conflict_reasons_after_task_update() + IS 'function which is called by task table update trigger, which deletes task_conflict_reasons when the task status is updated to !conflict.'; + +CREATE TRIGGER trigger_delete_conflict_reasons_after_task_update + AFTER UPDATE + ON resource_allocation.task + FOR EACH ROW + EXECUTE PROCEDURE resource_allocation.delete_conflict_reasons_after_task_update(); + +--------------------------------------------------------------------------------------------------------------------- + +DROP TRIGGER IF EXISTS trigger_before_insert_conflict_reason_do_task_status_check ON resource_allocation.task_conflict_reason CASCADE; +DROP FUNCTION IF EXISTS resource_allocation.before_insert_conflict_reason_do_task_status_check(); + +CREATE OR REPLACE FUNCTION resource_allocation.before_insert_conflict_reason_do_task_status_check() + RETURNS trigger AS +$BODY$ +BEGIN + -- check if referred task is in conflict status, else raise + IF (SELECT COUNT(id) FROM resource_allocation.task task WHERE task.id = NEW.task_id AND task.status_id = 335) = 0 THEN + RAISE EXCEPTION 'task has no conflict status'; + END IF; +RETURN NEW; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +ALTER FUNCTION resource_allocation.before_insert_conflict_reason_do_task_status_check() + OWNER TO resourceassignment; +COMMENT ON FUNCTION resource_allocation.before_insert_conflict_reason_do_task_status_check() + IS 'check if referred task is in conflict status, else raise'; + +CREATE TRIGGER trigger_before_insert_conflict_reason_do_task_status_check + BEFORE INSERT + ON resource_allocation.task_conflict_reason + FOR EACH ROW + EXECUTE PROCEDURE resource_allocation.before_insert_conflict_reason_do_task_status_check(); + +--------------------------------------------------------------------------------------------------------------------- diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/create_database.sql b/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/create_database.sql index 304bf26850d..b3e88820afa 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/create_database.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/create_database.sql @@ -27,6 +27,9 @@ DROP TABLE IF EXISTS resource_monitoring.resource_capacity CASCADE; DROP TABLE IF EXISTS resource_allocation.resource_claim_property CASCADE; DROP TABLE IF EXISTS resource_allocation.resource_claim_property_type CASCADE; DROP TABLE IF EXISTS resource_allocation.sap CASCADE; +DROP TABLE IF EXISTS resource_allocation.conflict_reason CASCADE; +DROP TABLE IF EXISTS resource_allocation.resource_claim_conflict_reason CASCADE; +DROP TABLE IF EXISTS resource_allocation.task_conflict_reason CASCADE; DROP TABLE IF EXISTS resource_allocation.resource_claim CASCADE; DROP TABLE IF EXISTS resource_allocation.resource_claim_status CASCADE; DROP TABLE IF EXISTS resource_allocation.claim_session CASCADE; @@ -187,6 +190,32 @@ CREATE TABLE resource_allocation.resource_claim ( ALTER TABLE resource_allocation.resource_claim OWNER TO resourceassignment; +CREATE TABLE resource_allocation.conflict_reason ( + id serial NOT NULL, + reason text NOT NULL, + PRIMARY KEY (id) +) WITH (OIDS=FALSE); +ALTER TABLE resource_allocation.conflict_reason + OWNER TO resourceassignment; + +CREATE TABLE resource_allocation.resource_claim_conflict_reason ( + id serial NOT NULL, + resource_claim_id integer NOT NULL REFERENCES resource_allocation.resource_claim ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE, + conflict_reason_id integer NOT NULL REFERENCES resource_allocation.conflict_reason ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE, + PRIMARY KEY (id) +) WITH (OIDS=FALSE); +ALTER TABLE resource_allocation.resource_claim_conflict_reason + OWNER TO resourceassignment; + +CREATE TABLE resource_allocation.task_conflict_reason ( + id serial NOT NULL, + task_id integer NOT NULL REFERENCES resource_allocation.task ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE, + conflict_reason_id integer NOT NULL REFERENCES resource_allocation.conflict_reason ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE, + PRIMARY KEY (id) +) WITH (OIDS=FALSE); +ALTER TABLE resource_allocation.task_conflict_reason + OWNER TO resourceassignment; + CREATE TABLE resource_allocation.sap ( id serial NOT NULL, resource_claim_id integer NOT NULL REFERENCES resource_allocation.resource_claim ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE, -- GitLab