From d2318c75f2de880afb8e73ce02b0c0e7d752e238 Mon Sep 17 00:00:00 2001 From: Jorrit Schaap <schaap@astron.nl> Date: Fri, 12 May 2017 14:30:21 +0000 Subject: [PATCH] Task #10811: check_new_claim_for_conflicts which sets claims to conflict when they don't fit. Added before insert check which only accepts new claims in claimed status --- .../sql/add_functions_and_triggers.sql | 98 +++++++++++++------ 1 file changed, 68 insertions(+), 30 deletions(-) diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_functions_and_triggers.sql b/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_functions_and_triggers.sql index d25417fd9aa..6bf8b99a0cb 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_functions_and_triggers.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/sql/add_functions_and_triggers.sql @@ -475,46 +475,56 @@ COMMENT ON FUNCTION resource_monitoring.get_max_resource_usage_between(_resource --------------------------------------------------------------------------------------------------------------------- -DROP FUNCTION IF EXISTS resource_monitoring.check_new_claim_for_conflicts(new_claim resource_allocation.resource_claim); +DROP FUNCTION IF EXISTS resource_monitoring.get_resource_claimable_capacity_between(_resource_id int, _lower timestamp, _upper timestamp); -CREATE OR REPLACE FUNCTION resource_monitoring.check_new_claim_for_conflicts(new_claim resource_allocation.resource_claim) - RETURNS void AS +CREATE OR REPLACE FUNCTION resource_monitoring.get_resource_claimable_capacity_between(_resource_id int, _lower timestamp, _upper timestamp) + RETURNS bigint AS $$ DECLARE -overlapping_claim RECORD; -claimed_status_id int; -allocated_status_id int; + allocated_status_id int := 1; --beware: hard coded instead of lookup for performance + max_resource_usage resource_monitoring.resource_usage; + max_resource_usage_value int; + available_capacity bigint; BEGIN - RAISE NOTICE ''; - RAISE NOTICE '------- resource_monitoring.check_new_claim_for_conflicts() -------'; - RAISE NOTICE 'new claim: %', new_claim; + SELECT * FROM resource_monitoring.get_max_resource_usage_between(_resource_id, allocated_status_id, _lower, _upper) INTO max_resource_usage; - SELECT id FROM resource_allocation.resource_claim_status WHERE name = 'claimed' LIMIT 1 INTO claimed_status_id; - SELECT id FROM resource_allocation.resource_claim_status WHERE name = 'allocated' LIMIT 1 INTO allocated_status_id; - - IF claimed_status_id IS NULL THEN - RAISE EXCEPTION 'resource_monitoring.check_new_claim_for_conflicts could not find claimed status id.'; + IF max_resource_usage IS NULL THEN + max_resource_usage_value := 0; + ELSE + max_resource_usage_value := max_resource_usage.usage; END IF; - IF allocated_status_id IS NULL THEN - RAISE EXCEPTION 'resource_monitoring.check_new_claim_for_conflicts could not find allocated status id.'; - END IF; + SELECT available FROM resource_monitoring.resource_capacity WHERE resource_id = _resource_id LIMIT 1 INTO available_capacity; + + RETURN available_capacity - max_resource_usage_value; +END; +$$ LANGUAGE plpgsql; +ALTER FUNCTION resource_monitoring.get_resource_claimable_capacity_between(_resource_id int, _lower timestamp, _upper timestamp) OWNER TO resourceassignment; +COMMENT ON FUNCTION resource_monitoring.get_resource_claimable_capacity_between(_resource_id int, _lower timestamp, _upper timestamp) + IS 'get the maximum resource usage for the given _resource_id for claims with given _claim_status_id in the period between the given _lower and _upper timestamps'; - RAISE NOTICE 'getresource_usage_at(%, %, %) %', new_claim.resource_id, claimed_status_id, new_claim.starttime, resource_monitoring.get_resource_usage_at(new_claim.resource_id, claimed_status_id, new_claim.starttime); +--------------------------------------------------------------------------------------------------------------------- - RAISE NOTICE 'get_max_resource_usage_between(%, %, %, %) %', new_claim.resource_id, claimed_status_id, new_claim.starttime,new_claim.endtime, resource_monitoring.get_max_resource_usage_between(new_claim.resource_id, claimed_status_id, new_claim.starttime, new_claim.endtime); +DROP FUNCTION IF EXISTS resource_monitoring.check_new_claim_for_conflicts(new_claim resource_allocation.resource_claim); - -- search for overlapping claims on the same resource - FOR overlapping_claim IN SELECT * - FROM resource_allocation.resource_claim rc - WHERE rc.resource_id = new_claim.resource_id - AND rc.id != new_claim.id - AND rc.starttime <= new_claim.endtime - AND rc.endtime >= new_claim.starttime - LOOP - --TODO: check if new claim fits in resource capacity minus overlapping_claim sizes and minus unaccounted_for_usage - RAISE NOTICE 'overlapping_claim: %', overlapping_claim; - END LOOP; +CREATE OR REPLACE FUNCTION resource_monitoring.check_new_claim_for_conflicts(new_claim resource_allocation.resource_claim) + RETURNS void AS +$$ +DECLARE +claimed_status_id int := 0; --beware: hard coded instead of lookup for performance +conflict_status_id int := 2; --beware: hard coded instead of lookup for performance +free_claimable_capacity bigint; +BEGIN + --only check claimes in claimed status + IF new_claim.status_id = claimed_status_id THEN + -- get the free free_claimable_capacity for this resource for this claim's time window + SELECT * FROM resource_monitoring.get_resource_claimable_capacity_between(new_claim.resource_id, new_claim.starttime, new_claim.endtime) INTO free_claimable_capacity; + + -- if new claim to large, set claim status to conflict + IF new_claim.claim_size > free_claimable_capacity THEN + UPDATE resource_allocation.resource_claim SET status_id=conflict_status_id WHERE id=new_claim.id; + END IF; + END IF; END; $$ LANGUAGE plpgsql; ALTER FUNCTION resource_monitoring.check_new_claim_for_conflicts(new_claim resource_allocation.resource_claim) OWNER TO resourceassignment; @@ -564,5 +574,33 @@ CREATE TRIGGER T_on_claim_insertupdatedelete --------------------------------------------------------------------------------------------------------------------- +DROP TRIGGER IF EXISTS T_before_claim_insertupdatedelete ON resource_allocation.resource_claim CASCADE; +DROP FUNCTION IF EXISTS resource_monitoring.before_claim_insertupdatedelete(); + +CREATE OR REPLACE FUNCTION resource_monitoring.before_claim_insertupdatedelete() + RETURNS trigger AS +$BODY$ +DECLARE + claimed_status_id int := 0; --beware: hard coded instead of lookup for performance +BEGIN + IF NEW.status_id != claimed_status_id THEN + RAISE EXCEPTION 'newly inserted claims should not have status other than claimed; claim: %', NEW; + END IF; + RETURN NEW; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +ALTER FUNCTION resource_monitoring.before_claim_insertupdatedelete() + OWNER TO resourceassignment; + +CREATE TRIGGER T_before_claim_insertupdatedelete + BEFORE INSERT + ON resource_allocation.resource_claim + FOR EACH ROW + EXECUTE PROCEDURE resource_monitoring.before_claim_insertupdatedelete(); + +--------------------------------------------------------------------------------------------------------------------- + COMMIT; -- GitLab