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 cf13d616bfd0500aaf56364bc4cff81d8297d448..dda1cb57c588033669f3afe7117893d05f0b8f50 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql @@ -254,11 +254,9 @@ BEGIN SELECT * from clock_timestamp() into proc_start; -- 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); - - 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); + INSERT INTO resource_allocation.resource_usage_delta (claim_id, resource_id, status_id, moment, delta) + VALUES (new_claim.id, new_claim.resource_id, new_claim.status_id, new_claim.starttime, new_claim.claim_size), + (new_claim.id, new_claim.resource_id, new_claim.status_id, new_claim.endtime, -new_claim.claim_size); -- with the two new delta entries, use the deltas table to rebuild the usages table from the claim's starttime onwards --TODO: use an upper limit as well? When? @@ -312,23 +310,19 @@ CREATE OR REPLACE FUNCTION resource_allocation.rebuild_resource_usages_from_clai RETURNS void AS $$ BEGIN - -- 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_delta IN EXCLUSIVE MODE; - - -- delete the relevant deltas (so we can re-enter them in this method) + -- delete all 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 _resource_id, _status_id, rc.starttime, rc.claim_size + INSERT INTO resource_allocation.resource_usage_delta (claim_id, resource_id, status_id, moment, delta) + (SELECT rc.id, _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 _resource_id, _status_id, rc.endtime, -rc.claim_size + INSERT INTO resource_allocation.resource_usage_delta (claim_id, resource_id, status_id, moment, delta) + (SELECT rc.id, _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); @@ -350,10 +344,6 @@ DECLARE 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. @@ -432,22 +422,8 @@ DECLARE BEGIN SELECT * from clock_timestamp() into proc_start; - -- TODO: have a reference from delta table to claim_id? - 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 - AND rud.delta = old_claim.claim_size - 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 - AND rud.delta = -old_claim.claim_size - LIMIT 1); + -- get rid of claim in delta's table (this should delete two entries, one for the starttime, and one for the endtime) + DELETE FROM resource_allocation.resource_usage_delta WHERE claim_id = old_claim.id; -- with the two removed delta entries, use the deltas table to rebuild the usages table from the claim's starttime onwards --TODO: use an upper limit as well? When? diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql index 43fdbe9599b0dbd983f90136fe788b1b5b7efbaf..a82dfe3779bc0bd495cdef58acc7d4601daeb4ca 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql @@ -354,6 +354,7 @@ CREATE INDEX resource_usage_status_id_idx CREATE TABLE resource_allocation.resource_usage_delta ( id serial NOT NULL, + claim_id integer NOT NULL, -- yes, this is a reference to resource_allocation.resource_claim.id, but it's not defined as a reference because it is already used in the before_insert trigger when the claim id does not exist in the claim table yet. We do the consistent bookkeeping in the trigger functions ourselves. resource_id integer NOT NULL REFERENCES virtual_instrument.resource ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE, status_id integer NOT NULL REFERENCES resource_allocation.resource_claim_status ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE, moment timestamp NOT NULL, @@ -370,7 +371,7 @@ CREATE INDEX resource_usage_delta_moment_idx USING btree (moment); CREATE INDEX resource_usage_delta_idx - ON resource_allocation.resource_usage_delta (resource_id, status_id); + ON resource_allocation.resource_usage_delta (claim_id, resource_id, status_id);