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 af8d1c7a5a0f729816691bb7830c48f5daa5715d..3a1fa02be0e2669357eaa0018b82ea0ff819b206 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql @@ -333,16 +333,6 @@ COMMENT ON FUNCTION resource_allocation.process_new_claim_into_resource_usages(n --------------------------------------------------------------------------------------------------------------------- --- 20180903: brainstorm with AK & JS: the resource_usages table is useful because it makes lookups faster. However, --- there are known bugs in inserting/updating the resource_usages table upon changes in resource_claims. --- We discussed the idea of using an additional deltas helper table: claims -> deltas -> usages. --- the current implementation goes diretly from claims -> usages, and loops over claims "opening" and "closing" in the usage table. --- Introducing the intermediate deltas table has the benefit of using simple sql sum's, and not keeping track of opening/closing claims. --- Highly recommended to give this a try in JIRA SW-35. - ---------------------------------------------------------------------------------------------------------------------- - - CREATE OR REPLACE FUNCTION resource_allocation.rebuild_resource_usages_from_claims() RETURNS void AS $$ @@ -380,53 +370,117 @@ COMMENT ON FUNCTION resource_allocation.rebuild_resource_usages_from_claims_for_ CREATE OR REPLACE FUNCTION resource_allocation.rebuild_resource_usages_from_claims_for_resource_of_status(_resource_id int, _status_id int) RETURNS void AS $$ -DECLARE - combined_delta_row record; - running_usage_sum bigint := 0; BEGIN - -- make sure nobody thouches these tables while running this function + -- make sure nobody touches these tables while running this function LOCK TABLE resource_allocation.resource_claim IN ACCESS SHARE MODE; - LOCK TABLE resource_allocation.resource_usage IN EXCLUSIVE MODE; LOCK TABLE resource_allocation.resource_usage_delta IN EXCLUSIVE MODE; - -- delete the relevant usages and deltas (so we can re-enter them in this method) - DELETE FROM resource_allocation.resource_usage WHERE resource_id = _resource_id AND status_id = _status_id; + -- delete the relevant deltas (so we can re-enter them in this method) DELETE FROM resource_allocation.resource_usage_delta WHERE resource_id = _resource_id AND status_id = _status_id; -- build up the delta's table by inserting positive claim_size delta's at all claim starttimes... INSERT INTO resource_allocation.resource_usage_delta (resource_id, status_id, moment, delta) - (SELECT rc.resource_id, rc.status_id, rc.starttime, rc.claim_size + (SELECT _resource_id, _status_id, rc.starttime, rc.claim_size FROM resource_allocation.resource_claim rc WHERE rc.resource_id = _resource_id AND rc.status_id = _status_id); -- ...and by inserting negative claim_size delta's at all claim endtimes INSERT INTO resource_allocation.resource_usage_delta (resource_id, status_id, moment, delta) - (SELECT rc.resource_id, rc.status_id, rc.endtime, -rc.claim_size + (SELECT _resource_id, _status_id, rc.endtime, -rc.claim_size FROM resource_allocation.resource_claim rc WHERE rc.resource_id = _resource_id AND rc.status_id = _status_id); - -- perform integration over delta's and insert into resource_usage - FOR combined_delta_row in (SELECT rud.moment, SUM(rud.delta) as summed_delta - FROM resource_allocation.resource_usage_delta rud - WHERE rud.resource_id = _resource_id - AND rud.status_id = _status_id - GROUP BY rud.moment - ORDER BY rud.moment) LOOP - --integrate - running_usage_sum := running_usage_sum + combined_delta_row.summed_delta; - - --and insert into resource_usage - INSERT INTO resource_allocation.resource_usage (resource_id, status_id, as_of_timestamp, usage) - VALUES (_resource_id, _status_id, combined_delta_row.moment, running_usage_sum); - END LOOP; + -- now that the deltas table has been rebuild, use it to rebuild the usages table + PERFORM resource_allocation.rebuild_resource_usages_from_deltas_for_resource_of_status(_resource_id, _status_id); END; $$ LANGUAGE plpgsql; ALTER FUNCTION resource_allocation.rebuild_resource_usages_from_claims_for_resource_of_status(int, int) OWNER TO resourceassignment; COMMENT ON FUNCTION resource_allocation.rebuild_resource_usages_from_claims_for_resource_of_status(int, int) IS 'function which rebuilds the resource_usages table for the claims with a specific status for a specific resource.'; + +CREATE OR REPLACE FUNCTION resource_allocation.rebuild_resource_usages_from_deltas_for_resource_of_status(_resource_id int, _status_id int, _since timestamp default NULL) + RETURNS void AS +$$ +DECLARE + combined_delta_row record; + running_usage_sum bigint; + usage_before_since resource_allocation.resource_usage; +BEGIN + -- make sure nobody touches these tables while running this function + LOCK TABLE resource_allocation.resource_usage_delta IN ACCESS SHARE MODE; + LOCK TABLE resource_allocation.resource_usage IN EXCLUSIVE MODE; + + -- here are two versions of the same algorithm + -- if _since is NULL, then run over the entire timespan + -- else, do time-bound queries which are slightly slower. + IF _since IS NULL THEN + -- delete the relevant usages + DELETE FROM resource_allocation.resource_usage + WHERE resource_id = _resource_id + AND status_id = _status_id; + + running_usage_sum := 0; + + -- perform integration over delta's and insert into resource_usage + FOR combined_delta_row in (SELECT rud.moment, SUM(rud.delta) as summed_delta + FROM resource_allocation.resource_usage_delta rud + WHERE rud.resource_id = _resource_id + AND rud.status_id = _status_id + GROUP BY rud.moment + ORDER BY rud.moment) LOOP + --integrate + running_usage_sum := running_usage_sum + combined_delta_row.summed_delta; + + --and insert into resource_usage + INSERT INTO resource_allocation.resource_usage (resource_id, status_id, as_of_timestamp, usage) + VALUES (_resource_id, _status_id, combined_delta_row.moment, running_usage_sum); + END LOOP; + ELSE + -- same alghorithm as above, but now timerange-bound as of _since + -- delete the relevant usages + DELETE FROM resource_allocation.resource_usage + WHERE resource_id = _resource_id + AND status_id = _status_id + AND as_of_timestamp >= _since; + + -- get the usage_before_since to initialize running_usage_sum with + SELECT * FROM resource_allocation.get_resource_usage_at_or_before(_resource_id, _status_id, _since, false, true, false) + INTO usage_before_since; + + IF usage_before_since is NULL THEN + running_usage_sum := 0; + ELSE + running_usage_sum := usage_before_since.usage; + END IF; + + -- perform integration over delta's since _since and insert into resource_usage + FOR combined_delta_row in (SELECT rud.moment, SUM(rud.delta) as summed_delta + FROM resource_allocation.resource_usage_delta rud + WHERE rud.resource_id = _resource_id + AND rud.status_id = _status_id + AND rud.moment >= _since + GROUP BY rud.moment + ORDER BY rud.moment) LOOP + --integrate + running_usage_sum := running_usage_sum + combined_delta_row.summed_delta; + + --and insert into resource_usage + INSERT INTO resource_allocation.resource_usage (resource_id, status_id, as_of_timestamp, usage) + VALUES (_resource_id, _status_id, combined_delta_row.moment, running_usage_sum); + END LOOP; + END IF; +END; +$$ LANGUAGE plpgsql; +ALTER FUNCTION resource_allocation.rebuild_resource_usages_from_deltas_for_resource_of_status(int, int, timestamp) OWNER TO resourceassignment; +COMMENT ON FUNCTION resource_allocation.rebuild_resource_usages_from_deltas_for_resource_of_status(int, int, timestamp) + IS 'function which rebuilds the resource_usages table from the resource_usage_deltas table with a specific status for a specific resource since a given timestamp.'; + +--------------------------------------------------------------------------------------------------------------------- + + --------------------------------------------------------------------------------------------------------------------- CREATE OR REPLACE FUNCTION resource_allocation.process_old_claim_outof_resource_usages(old_claim resource_allocation.resource_claim) RETURNS void AS