From 0c5a788c7cf24ed6b4bde6baaf3ec89b5d86101d Mon Sep 17 00:00:00 2001 From: Jorrit Schaap <schaap@astron.nl> Date: Fri, 9 Nov 2018 14:34:47 +0000 Subject: [PATCH] SW-44: major simplification of process_new_claim_into_resource_usages and process_old_claim_outof_resource_usages using the new deltas table. Now the new test_20181108_bugfix_resource_usages passes as well, and preliminary results indicate a performance boost as well. --- .../radb/sql/add_functions_and_triggers.sql | 156 +++--------------- 1 file changed, 21 insertions(+), 135 deletions(-) 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 3a1fa02be0e..604f5e5d88c 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql @@ -248,80 +248,20 @@ CREATE OR REPLACE FUNCTION resource_allocation.process_new_claim_into_resource_u RETURNS void AS $$ DECLARE - usage_at_or_before_start resource_allocation.resource_usage; - usage_at_or_before_end resource_allocation.resource_usage; - intermediate_usage resource_allocation.resource_usage; proc_start timestamp with time zone; proc_end timestamp with time zone; - part_start timestamp with time zone; - part_end timestamp with time zone; BEGIN SELECT * from clock_timestamp() into proc_start; - SELECT * from clock_timestamp() into part_start; - - -- find resource_usage at claim starttime - SELECT * FROM resource_allocation.get_resource_usage_at_or_before(new_claim.resource_id, new_claim.status_id, new_claim.starttime, false, false, false) into usage_at_or_before_start; - SELECT * FROM resource_allocation.get_resource_usage_at_or_before(new_claim.resource_id, new_claim.status_id, new_claim.endtime, false, false, false) into usage_at_or_before_end; - - SELECT * from clock_timestamp() into part_end; - RAISE NOTICE 'process_new_claim_into_resource_usages1 took %', part_end - part_start; - SELECT * from clock_timestamp() into part_start; - - --add new_claim.claim_size at claim starttime to resource_usage depending on state of usage_at_or_before_start - IF usage_at_or_before_start IS NOT NULL THEN - IF usage_at_or_before_start.as_of_timestamp = new_claim.starttime THEN - --update at the claim starttime the already existing usage value at the claim starttime + new claim size - UPDATE resource_allocation.resource_usage ru SET usage = usage_at_or_before_start.usage + new_claim.claim_size - WHERE ru.id = usage_at_or_before_start.id; - ELSE - --insert at the claim starttime the existing usage value before claim starttime + new claim size - INSERT INTO resource_allocation.resource_usage (resource_id, status_id, as_of_timestamp, usage) - VALUES (new_claim.resource_id, new_claim.status_id, new_claim.starttime, usage_at_or_before_start.usage + new_claim.claim_size); - END IF; - ELSE - -- no previous usage known, so insert this claim's size as the first usage - INSERT INTO resource_allocation.resource_usage (resource_id, status_id, as_of_timestamp, usage) - VALUES (new_claim.resource_id, new_claim.status_id, new_claim.starttime, new_claim.claim_size); - END IF; - --close resource_usage for this new_claim claim at claim endtime depending on state of usage_at_or_before_end - IF usage_at_or_before_end IS NOT NULL THEN - IF usage_at_or_before_end.as_of_timestamp <> new_claim.endtime THEN - --insert at the claim endtime the existing usage value before claim endtime - INSERT INTO resource_allocation.resource_usage (resource_id, status_id, as_of_timestamp, usage) - VALUES (new_claim.resource_id, new_claim.status_id, new_claim.endtime, usage_at_or_before_end.usage); - END IF; - --TODO: 20180709; why no else with an upate? - ELSE - -- no previous usage known, so insert 0 as the last usage - INSERT INTO resource_allocation.resource_usage (resource_id, status_id, as_of_timestamp, usage) - VALUES (new_claim.resource_id, new_claim.status_id, new_claim.endtime, 0); - END IF; - - SELECT * from clock_timestamp() into part_end; - RAISE NOTICE 'process_new_claim_into_resource_usages2 took %', part_end - part_start; - SELECT * from clock_timestamp() into part_start; - - --now modify any existing usages between new_claim claim starttime and endtime - FOR intermediate_usage IN SELECT * FROM resource_allocation.resource_usage ru - WHERE ru.resource_id = new_claim.resource_id - AND ru.status_id = new_claim.status_id - AND ru.as_of_timestamp > new_claim.starttime - AND ru.as_of_timestamp < new_claim.endtime - LOOP - UPDATE resource_allocation.resource_usage ru SET usage = intermediate_usage.usage + new_claim.claim_size - WHERE ru.id = intermediate_usage.id; - END LOOP; + -- insert the claim's start and end delta + INSERT INTO resource_allocation.resource_usage_delta (resource_id, status_id, moment, delta) + VALUES (new_claim.resource_id, new_claim.status_id, new_claim.starttime, new_claim.claim_size); - -- 20181024: possible candidate for speedup of for loop above? --- UPDATE resource_allocation.resource_usage ru --- SET usage = ru.usage + new_claim.claim_size --- WHERE ru.resource_id = new_claim.resource_id --- AND ru.status_id = new_claim.status_id --- AND between new_claim.starttime and new_claim.endtime; + INSERT INTO resource_allocation.resource_usage_delta (resource_id, status_id, moment, delta) + VALUES (new_claim.resource_id, new_claim.status_id, new_claim.endtime, -new_claim.claim_size); - SELECT * from clock_timestamp() into part_end; - RAISE NOTICE 'process_new_claim_into_resource_usages3 took %', part_end - part_start; + -- with the two new delta entries, use the deltas table to rebuild the usages table from the claim's starttime onwards + PERFORM resource_allocation.rebuild_resource_usages_from_deltas_for_resource_of_status(new_claim.resource_id, new_claim.status_id, new_claim.starttime); SELECT * from clock_timestamp() into proc_end; RAISE NOTICE 'process_new_claim_into_resource_usages took %', proc_end - proc_start; @@ -486,78 +426,27 @@ CREATE OR REPLACE FUNCTION resource_allocation.process_old_claim_outof_resource_ RETURNS void AS $$ DECLARE - usage_at_start RECORD; - usage_before_start RECORD; - usage_at_end RECORD; - intermediate_usage RECORD; proc_start timestamp with time zone; proc_end timestamp with time zone; - part_start timestamp with time zone; - part_end timestamp with time zone; BEGIN SELECT * from clock_timestamp() into proc_start; - SELECT * from clock_timestamp() into part_start; - -- find resource_usage at claim starttime - SELECT * FROM resource_allocation.get_resource_usage_at_or_before(old_claim.resource_id, old_claim.status_id, old_claim.starttime, true, false, true) into usage_at_start; - - IF usage_at_start IS NULL THEN - RAISE EXCEPTION 'process_old_claim_outof_resource_usages(%) cannot find usage_at_start', old_claim; - END IF; + DELETE FROM resource_allocation.resource_usage_delta + WHERE id = (SELECT id FROM resource_allocation.resource_usage_delta rud + WHERE rud.resource_id = old_claim.resource_id + AND rud.status_id = old_claim.status_id + AND rud.moment = old_claim.starttime + LIMIT 1); + DELETE FROM resource_allocation.resource_usage_delta + WHERE id = (SELECT id FROM resource_allocation.resource_usage_delta rud + WHERE rud.resource_id = old_claim.resource_id + AND rud.status_id = old_claim.status_id + AND rud.moment = old_claim.endtime + LIMIT 1); - -- and find resource_usage at claim endtime - SELECT * FROM resource_allocation.get_resource_usage_at_or_before(old_claim.resource_id, old_claim.status_id, old_claim.endtime, true, false, true) into usage_at_end; - - IF usage_at_end IS NULL THEN - RAISE EXCEPTION 'process_old_claim_outof_resource_usages(%) cannot find usage_at_end', old_claim; - END IF; - - SELECT * from clock_timestamp() into part_end; - RAISE NOTICE 'process_old_claim_outof_resource_usage1 took %', part_end - part_start; - SELECT * from clock_timestamp() into part_start; - - IF usage_at_start.usage = old_claim.claim_size THEN - IF usage_at_end.usage = 0 THEN - -- find resource_usage before claim starttime - SELECT * FROM resource_allocation.get_resource_usage_at_or_before(old_claim.resource_id, old_claim.status_id, old_claim.starttime, false, true, false) into usage_before_start; - - IF usage_before_start IS NULL OR (usage_before_start IS NOT NULL AND usage_before_start.usage = 0) THEN - --usage_at_start was 'caused' by this deleted claim only, so delete it - DELETE FROM resource_allocation.resource_usage ru WHERE ru.id = usage_at_start.id; - ELSE - UPDATE resource_allocation.resource_usage ru SET usage = 0 WHERE ru.id = usage_at_start.id; - END IF; - ELSE - --usage_at_start was 'caused' by this deleted claim only, so delete it - DELETE FROM resource_allocation.resource_usage ru WHERE ru.id = usage_at_start.id; - END IF; - ELSE - --update the usage_at_start.usage by subtracting the deleted claim size - UPDATE resource_allocation.resource_usage ru SET usage = usage_at_start.usage - old_claim.claim_size - WHERE ru.id = usage_at_start.id; - END IF; - - IF usage_at_end.usage = 0 THEN - --usage_at_end was 'caused' by this deleted claim only, so delete it - --TODO:20180704 do not delete if another claim with this status and timestamp also causes this 0 - DELETE FROM resource_allocation.resource_usage ru WHERE ru.id = usage_at_end.id; - END IF; - - SELECT * from clock_timestamp() into part_end; - RAISE NOTICE 'process_old_claim_outof_resource_usage2 took %', part_end - part_start; - SELECT * from clock_timestamp() into part_start; - - --now modify any existing usages between old_claim claim starttime and endtime - FOR intermediate_usage IN SELECT * FROM resource_allocation.resource_usage ru - WHERE ru.resource_id = old_claim.resource_id - AND ru.status_id = old_claim.status_id - AND ru.as_of_timestamp > old_claim.starttime - AND ru.as_of_timestamp < old_claim.endtime - LOOP - UPDATE resource_allocation.resource_usage ru SET usage = intermediate_usage.usage - old_claim.claim_size - WHERE ru.id = intermediate_usage.id; - END LOOP; + -- with the two removed delta entries, use the deltas table to rebuild the usages table from the claim's starttime onwards + PERFORM resource_allocation.rebuild_resource_usages_from_deltas_for_resource_of_status(old_claim.resource_id, old_claim.status_id, old_claim.starttime); SELECT * from clock_timestamp() into proc_end; RAISE NOTICE 'process_old_claim_outof_resource_usages took %', proc_end - proc_start; @@ -643,7 +532,6 @@ DECLARE BEGIN SELECT * FROM utcnow() INTO now; SELECT * FROM resource_allocation.get_resource_usage_at_or_before(_resource_id, _claim_status_id, now, false, false, false) into result; - RAISE NOTICE 'get_current_resource_usage(%, %) at % is %', _resource_id, _claim_status_id, now, result; RETURN result; END; $$ LANGUAGE plpgsql; @@ -768,8 +656,6 @@ BEGIN -- this does not include the current claim which is (or at least should be) tentative. SELECT * FROM resource_allocation.get_resource_claimable_capacity_between(claim.resource_id, claim.starttime, claim.endtime) INTO free_claimable_capacity; - RAISE NOTICE 'has_conflict_with_overlapping_claims(%) free_claimable_capacity=%', claim, free_claimable_capacity; - SELECT * from clock_timestamp() into proc_end; RAISE NOTICE 'has_conflict_with_overlapping_claims took %', proc_end - proc_start; -- GitLab