From 39b0c3819fc07ac76fc7ed19fd486d08a988fff6 Mon Sep 17 00:00:00 2001 From: Jorrit Schaap <schaap@astron.nl> Date: Fri, 1 Sep 2017 11:44:15 +0000 Subject: [PATCH] Task #10902: fixed and improve (on speed) the rebuild_resource_usages_table_from_claims nethod. Extended the test_resource_usages. Added performance test script which proves the new rebuild is O(N) and about n order of magnitude faster than before. --- .gitattributes | 1 + .../ResourceAssignmentDatabase/radb.py | 41 ++-- .../radb/sql/add_functions_and_triggers.sql | 230 ++++++++++++++++-- .../radb/sql/create_database.sql | 17 ++ .../tests/radb_performance_test.py | 113 +++++++++ .../tests/t_radb.py | 227 +++++++++++------ 6 files changed, 511 insertions(+), 118 deletions(-) create mode 100755 SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/radb_performance_test.py diff --git a/.gitattributes b/.gitattributes index 4a5803746df..2c605e59fae 100644 --- a/.gitattributes +++ b/.gitattributes @@ -4874,6 +4874,7 @@ SAS/ResourceAssignment/ResourceAssignmentDatabase/radbpglistener -text SAS/ResourceAssignment/ResourceAssignmentDatabase/radbpglistener.ini -text SAS/ResourceAssignment/ResourceAssignmentDatabase/radbpglistener.py -text SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/CMakeLists.txt -text +SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/radb_performance_test.py -text SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/t_radb.py -text SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/t_radb.run -text SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/t_radb.sh -text diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb.py b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb.py index 118bacccc64..3d7c5993f52 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb.py +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb.py @@ -78,9 +78,11 @@ class RADatabase: self.cursor.execute(query, qargs) if self.log_queries: elapsed = datetime.utcnow() - start - logger.info('executed query in %.1fms yielding %s rows: %s', 1000.0*totalSeconds(elapsed), - self.cursor.rowcount, - self._queryAsSingleLine(query, qargs)) + elapsed_ms = 1000.0 * totalSeconds(elapsed) + logger.info('executed query in %.1fms%s yielding %s rows: %s', elapsed_ms, + ' (SLOW!)' if elapsed_ms > 250 else '', # for easy log grep'ing + self.cursor.rowcount, + self._queryAsSingleLine(query, qargs)) break except (psycopg2.OperationalError, AttributeError) as e: if isinstance(e, psycopg2.OperationalError): @@ -806,13 +808,7 @@ class RADatabase: claim_status_id = claim_status query = '''SELECT * from resource_allocation.get_current_resource_usage(%s, %s)''' - result = self._executeQuery(query, (resource_id, claim_status_id), fetch=_FETCH_ONE) - - if result is None or result.get('usage') is None: - #return a nice default - result = {'usage': 0, 'status_id': claim_status_id, 'id': None, 'as_of_timestamp': timestamp, 'resource_id': resource_id} - - return result + return self._executeQuery(query, (resource_id, claim_status_id), fetch=_FETCH_ONE) def get_resource_usage_at_or_before(self, resource_id, timestamp, claim_status='claimed', exactly_at=False, only_before=False): if isinstance(claim_status, basestring): @@ -821,13 +817,7 @@ class RADatabase: claim_status_id = claim_status query = '''SELECT * from resource_allocation.get_resource_usage_at_or_before(%s, %s, %s, %s, %s, %s)''' - result = self._executeQuery(query, (resource_id, claim_status_id, timestamp, exactly_at, only_before, True), fetch=_FETCH_ONE) - - if result is None or result.get('usage') is None: - #return a nice default - result = {'usage': 0, 'status_id': claim_status_id, 'id': None, 'as_of_timestamp': timestamp, 'resource_id': resource_id} - - return result + return self._executeQuery(query, (resource_id, claim_status_id, timestamp, exactly_at, only_before, False), fetch=_FETCH_ONE) def updateResourceAvailability(self, resource_id, active=None, available_capacity=None, total_capacity=None, commit=True): if active is not None: @@ -1309,7 +1299,7 @@ class RADatabase: claimIds = [x['id'] for x in self._executeQuery(query, fetch=_FETCH_ALL)] if not claimIds or [x for x in claimIds if x < 0]: - logger.error("One or more claims cloud not be inserted. Rolling back.") + logger.error("One or more claims could not be inserted. Rolling back.") self.rollback() return [] @@ -1535,10 +1525,19 @@ class RADatabase: result['claimable_capacity'] = qresult.get('get_resource_claimable_capacity_between', 0) return result - def rebuild_resource_usages_table_from_claims(self): + def rebuild_resource_usages_from_claims(self, resource_id=None, claim_status=None): '''(re)builds the resource_usages table from all currently known resource_claims''' - query = '''SELECT * from resource_allocation.rebuild_resource_usages_table_from_claims()''' - self._executeQuery(query, fetch=_FETCH_NONE) + if isinstance(claim_status, basestring): + claim_status_id = self.getResourceClaimStatusId(claim_status) + else: + claim_status_id = claim_status + + if resource_id is None and claim_status_id is None: + self._executeQuery('SELECT * from resource_allocation.rebuild_resource_usages_from_claims()', fetch=_FETCH_NONE) + elif claim_status_id is None: + self._executeQuery('SELECT * from resource_allocation.rebuild_resource_usages_from_claims_for_resource(%s)', (resource_id,), fetch=_FETCH_NONE) + else: + self._executeQuery('SELECT * from resource_allocation.rebuild_resource_usages_from_claims_for_resource_of_status(%s, %s)', (resource_id, claim_status_id), fetch=_FETCH_NONE) def insertSpecificationAndTask(self, mom_id, otdb_id, task_status, task_type, starttime, endtime, content, cluster, commit=True): ''' 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 b9656b4f501..152e5d1a96d 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/add_functions_and_triggers.sql @@ -316,46 +316,244 @@ COMMENT ON FUNCTION resource_allocation.process_new_claim_into_resource_usages(n --------------------------------------------------------------------------------------------------------------------- -CREATE OR REPLACE FUNCTION resource_allocation.rebuild_resource_usages_table_from_claims() +CREATE OR REPLACE FUNCTION resource_allocation.rebuild_resource_usages_from_claims() RETURNS void AS $$ DECLARE resource virtual_instrument.resource; BEGIN FOR resource IN (SELECT * FROM virtual_instrument.resource ORDER BY id) LOOP - --TODO: permance boost possible when taking advantage of fact that we are looping in time sequential order. (less seeks (selects) needed) - PERFORM resource_allocation.rebuild_resource_usages_table_from_claims_for_resource(resource.id); + PERFORM resource_allocation.rebuild_resource_usages_from_claims_for_resource(resource.id); END LOOP; END; $$ LANGUAGE plpgsql; -ALTER FUNCTION resource_allocation.rebuild_resource_usages_table_from_claims() OWNER TO resourceassignment; -COMMENT ON FUNCTION resource_allocation.rebuild_resource_usages_table_from_claims() +ALTER FUNCTION resource_allocation.rebuild_resource_usages_from_claims() OWNER TO resourceassignment; +COMMENT ON FUNCTION resource_allocation.rebuild_resource_usages_from_claims() IS 'function which truncates the resource_usages table, and repopulates it by calling process_new_claim_into_resource_usages for each known claim.'; --------------------------------------------------------------------------------------------------------------------- -CREATE OR REPLACE FUNCTION resource_allocation.rebuild_resource_usages_table_from_claims_for_resource(_resource_id int) +CREATE OR REPLACE FUNCTION resource_allocation.rebuild_resource_usages_from_claims_for_resource(_resource_id int) + RETURNS void AS +$$ +DECLARE + status resource_allocation.resource_claim_status; +BEGIN + FOR status IN (SELECT * FROM resource_allocation.resource_claim_status ORDER BY id) LOOP + PERFORM resource_allocation.rebuild_resource_usages_from_claims_for_resource_of_status(_resource_id, status.id); + END LOOP; +END; +$$ LANGUAGE plpgsql; +ALTER FUNCTION resource_allocation.rebuild_resource_usages_from_claims_for_resource(_resource_id int) OWNER TO resourceassignment; +COMMENT ON FUNCTION resource_allocation.rebuild_resource_usages_from_claims_for_resource(_resource_id int) + IS 'function which rebuilds the resource_usages table for a specific resource.'; + +--------------------------------------------------------------------------------------------------------------------- + +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 claim resource_allocation.resource_claim; - usage resource_allocation.resource_usage; + finished_claim resource_allocation.resource_claim; + tmp_usage resource_allocation.resource_usage; + new_usage_value bigint := 0; + new_usage_id integer; BEGIN + -- make sure nobody thouches the 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; - DELETE FROM resource_allocation.resource_usage WHERE resource_id = _resource_id; + LOCK TABLE resource_allocation._rebuild_usages_active_claims IN EXCLUSIVE MODE; + + -- delete the relevant usages (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; + + -- make sure the helper tables are empty + TRUNCATE resource_allocation._rebuild_usages_active_claims; --tracks the 'open'/'active' claims (starttime < loop_timestamp < endtime) + TRUNCATE resource_allocation._rebuild_usages_active_usages; --will be filled with small subset of usages-table for faster lookups than in the big reource_usage table. + + -- process each claim for this _resource_id with _status_id + FOR claim IN (SELECT * FROM resource_allocation.resource_claim + WHERE resource_id = _resource_id + AND status_id = _status_id + ORDER BY starttime, endtime) + LOOP + -- keep helper table _rebuild_usages_active_usages small and quick-to-search in each iteration. + -- delete all 'closed'/'obsolete' usages from + -- any usage before the first usage before min(endtime) of the active_claims is obsolete. (yes, that's twice before) + SELECT * FROM resource_allocation._rebuild_usages_active_usages ru + WHERE ru.as_of_timestamp < (SELECT MIN(endtime) FROM resource_allocation._rebuild_usages_active_claims) + ORDER BY ru.as_of_timestamp DESC + LIMIT 1 + INTO tmp_usage; + IF tmp_usage IS NOT NULL THEN + -- remember from above? any usage before the first usage before min(starttime) of the active_claims is obsolete. + -- so, select the first usage before the usage we just found. + SELECT * FROM resource_allocation._rebuild_usages_active_usages ru + WHERE ru.as_of_timestamp < tmp_usage.as_of_timestamp + ORDER BY ru.as_of_timestamp DESC + LIMIT 1 + INTO tmp_usage; + + IF tmp_usage IS NOT NULL THEN + DELETE FROM resource_allocation._rebuild_usages_active_usages ru WHERE ru.as_of_timestamp < tmp_usage.as_of_timestamp; + END IF; + END IF; + + --'close' all finished claims (if any) + FOR finished_claim IN (SELECT * FROM resource_allocation._rebuild_usages_active_claims ac + WHERE ac.endtime <= claim.starttime + ORDER BY endtime) + LOOP + --(quick) search in the (small) _rebuild_usages_active_usages which holds only relevant usages + --find last usage at or before finished_claim.endtime + SELECT * FROM resource_allocation._rebuild_usages_active_usages ru + WHERE ru.as_of_timestamp <= finished_claim.endtime + ORDER BY ru.as_of_timestamp DESC + LIMIT 1 + INTO tmp_usage; + + IF tmp_usage IS NULL THEN + RAISE EXCEPTION 'tmp_usage should not be NULL while finishing active claims for claim % in rebuild_resource_usages_from_claims_for_resource_of_status(%, %)', finished_claim, _resource_id, _status_id; + END IF; + + -- integrate (add current value to previous value) + new_usage_value := tmp_usage.usage - finished_claim.claim_size; + + --a finished claim is 'closed' by subtracting the claim_size from the last usage value + --this happens either at an already existing usage timestamp, or at a new usage timestamp. + IF finished_claim.endtime = tmp_usage.as_of_timestamp THEN + --claim's endtime coincides with existing usage timestamp + --update the existing usage into the table + UPDATE resource_allocation.resource_usage + SET usage = new_usage_value + WHERE id = tmp_usage.id; + + --also update the usage in the the small _rebuild_usages_active_usages table. + UPDATE resource_allocation._rebuild_usages_active_usages + SET usage = new_usage_value + WHERE id = tmp_usage.id; + ELSE + --claim's endtime does not coincide with existing usage timestamp + --insert the new usage into the table + INSERT INTO resource_allocation.resource_usage (resource_id, status_id, as_of_timestamp, usage) + VALUES (_resource_id, _status_id, finished_claim.endtime, new_usage_value) RETURNING id INTO new_usage_id; + + --also add the usage to the small _rebuild_usages_active_usages table, so it can be (quickly) searched. + INSERT INTO resource_allocation._rebuild_usages_active_usages (id, resource_id, status_id, as_of_timestamp, usage) + VALUES (new_usage_id, _resource_id, _status_id, finished_claim.endtime, new_usage_value); + END IF; - FOR claim IN (SELECT * FROM resource_allocation.resource_claim WHERE resource_id = _resource_id ORDER BY starttime, endtime) LOOP - PERFORM resource_allocation.process_new_claim_into_resource_usages(claim); + --now that the claim has been 'closed', remove it from the active claims + DELETE FROM resource_allocation._rebuild_usages_active_claims WHERE id = finished_claim.id; + END LOOP; -- end loop over finished claims + + --all claims which finished at or before this claim's starttime are now closed. + --now, handle the new 'active' claim + + --(quick) search in the (small) _rebuild_usages_active_usages which holds only relevant usages + --find last usage at or before claim.starttime + SELECT * FROM resource_allocation._rebuild_usages_active_usages ru + WHERE ru.as_of_timestamp <= claim.starttime + ORDER BY ru.as_of_timestamp DESC + LIMIT 1 + INTO tmp_usage; + + --this 'active' claim 'opens' also either at an already existing usage timestamp or at a new usage timestamp. + IF tmp_usage IS NOT NULL AND claim.starttime = tmp_usage.as_of_timestamp THEN + --claim's starttime coincides with existing usage timestamp + -- integrate (add current value to previous value) + new_usage_value := tmp_usage.usage + claim.claim_size; + + --update the existing usage with the new_usage_value + UPDATE resource_allocation.resource_usage + SET usage = new_usage_value + WHERE id = tmp_usage.id; + + --also update the small _rebuild_usages_active_usages table, so it can be (quickly) searched. + UPDATE resource_allocation._rebuild_usages_active_usages + SET usage = new_usage_value + WHERE id = tmp_usage.id; + ELSE + --claim's starttime does not coincide with existing usage timestamp + IF tmp_usage IS NULL THEN + -- integrate (no previous value, so start of integral) + new_usage_value := claim.claim_size; + ELSE + -- integrate (add current value to previous value) + new_usage_value := tmp_usage.usage + claim.claim_size; + END IF; + + --and insert the new usage into the table + INSERT INTO resource_allocation.resource_usage (resource_id, status_id, as_of_timestamp, usage) + VALUES (_resource_id, _status_id, claim.starttime, new_usage_value) RETURNING id INTO new_usage_id; + + --also add the usage to the small _rebuild_usages_active_usages table, so it can be (quickly) searched. + INSERT INTO resource_allocation._rebuild_usages_active_usages (id, resource_id, status_id, as_of_timestamp, usage) + VALUES (new_usage_id, _resource_id, _status_id, claim.starttime, new_usage_value); + END IF; + + --now that the claim has been 'opened', add it to the active claims + INSERT INTO resource_allocation._rebuild_usages_active_claims (id, resource_id, task_id, starttime, endtime, status_id, claim_size) + VALUES (claim.id, claim.resource_id, claim.task_id, claim.starttime, claim.endtime, claim.status_id, claim.claim_size); END LOOP; + + --all claims were processed and at least opened + --so, conclude with 'closing' all still active claims + FOR finished_claim IN (SELECT * FROM resource_allocation._rebuild_usages_active_claims ac + ORDER BY endtime) + LOOP + -- (quick) search in the (small) _rebuild_usages_active_usages which holds only relevant usages + SELECT * FROM resource_allocation._rebuild_usages_active_usages ru + WHERE ru.as_of_timestamp <= finished_claim.endtime + ORDER BY ru.as_of_timestamp DESC + LIMIT 1 + INTO tmp_usage; + + IF tmp_usage IS NULL THEN + RAISE EXCEPTION 'tmp_usage should not be NULL while finishing processing opened claims for claim % in rebuild_resource_usages_from_claims_for_resource_of_status(%, %)', finished_claim, _resource_id, _status_id; + END IF; + + -- integrate (add current value to previous value) + new_usage_value := tmp_usage.usage - finished_claim.claim_size; + + --a finished claim is 'closed' by subtracting the claim_size from the last_usage_value + --this happens either at an already existing usage timestamp, or at a new usage timestamp. + IF finished_claim.endtime = tmp_usage.as_of_timestamp THEN + --claim's endtime coincides with existing usage timestamp + UPDATE resource_allocation.resource_usage + SET usage = new_usage_value + WHERE id = tmp_usage.id; + + --also update the small _rebuild_usages_active_usages table, so it can be (quickly) searched. + UPDATE resource_allocation._rebuild_usages_active_usages + SET usage = new_usage_value + WHERE id = tmp_usage.id; + ELSE + --claim's endtime does not coincide with existing usage timestamp + --insert the new usage into the table + INSERT INTO resource_allocation.resource_usage (resource_id, status_id, as_of_timestamp, usage) + VALUES (_resource_id, _status_id, finished_claim.endtime, new_usage_value) RETURNING id INTO new_usage_id; + + --also add the usage to the small _rebuild_usages_active_usages table, so it can be (quickly) searched. + INSERT INTO resource_allocation._rebuild_usages_active_usages (id, resource_id, status_id, as_of_timestamp, usage) + VALUES (new_usage_id, _resource_id, _status_id, finished_claim.endtime, new_usage_value); + END IF; + + --now that the claim has been 'closed', remove it from the active claims + DELETE FROM resource_allocation._rebuild_usages_active_claims WHERE id = finished_claim.id; + END LOOP; + + -- wipe the helper tables + TRUNCATE resource_allocation._rebuild_usages_active_claims; + TRUNCATE resource_allocation._rebuild_usages_active_usages; END; $$ LANGUAGE plpgsql; -ALTER FUNCTION resource_allocation.rebuild_resource_usages_table_from_claims_for_resource(_resource_id int) OWNER TO resourceassignment; -COMMENT ON FUNCTION resource_allocation.rebuild_resource_usages_table_from_claims_for_resource(_resource_id int) - IS 'function which rebuilds the resource_usages table for a specific resource.'; +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.process_old_claim_outof_resource_usages(old_claim resource_allocation.resource_claim) RETURNS void AS $$ @@ -455,7 +653,7 @@ BEGIN -- rebuild usage when not found IF rebuild_usage_when_not_found AND result IS NULL THEN RAISE NOTICE 'get_resource_usage_at_or_before(_resource_id=%, status_id=%, timestamp=%, exactly_at=%, only_before=%, rebuild_usage_when_not_found=%): result should not be NULL. Rebuilding usages table for resource %.', _resource_id, _claim_status_id, _timestamp, exactly_at, only_before, rebuild_usage_when_not_found, _resource_id; - PERFORM resource_allocation.rebuild_resource_usages_table_from_claims_for_resource(_resource_id); + PERFORM resource_allocation.rebuild_resource_usages_from_claims_for_resource_of_status(_resource_id, _claim_status_id); RAISE NOTICE 'get_resource_usage_at_or_before(_resource_id=%, status_id=%, timestamp=%, exactly_at=%, only_before=%, rebuild_usage_when_not_found=%): Finished rebuilding usages table for resource %.', _resource_id, _claim_status_id, _timestamp, exactly_at, only_before, rebuild_usage_when_not_found, _resource_id; -- try again, but now without the option to rebuild_usage_when_not_found (to prevent endless recursion) @@ -480,7 +678,7 @@ COMMENT ON FUNCTION resource_allocation.get_resource_usage_at_or_before(int, int --------------------------------------------------------------------------------------------------------------------- -CREATE FUNCTION utcnow() +CREATE OR REPLACE FUNCTION utcnow() RETURNS timestamp AS $$ SELECT NOW() AT TIME ZONE 'UTC'; diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql index 13332c92d7f..40337a9dc5f 100644 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/radb/sql/create_database.sql @@ -251,6 +251,15 @@ CREATE INDEX resource_claim_resource_id_idx CREATE INDEX resource_claim_status_id_idx ON resource_allocation.resource_claim (status_id); +CREATE TABLE resource_allocation._rebuild_usages_active_claims ( LIKE resource_allocation.resource_claim INCLUDING INDEXES INCLUDING CONSTRAINTS ); +DROP INDEX resource_allocation._rebuild_usages_active_claims_resource_id_idx; --remove unnecessary index +DROP INDEX resource_allocation._rebuild_usages_active_claims_status_id_idx; --remove unnecessary index +DROP INDEX resource_allocation._rebuild_usages_active_claims_task_id_idx; --remove unnecessary index +ALTER TABLE resource_allocation._rebuild_usages_active_claims + OWNER TO resourceassignment; +COMMENT ON TABLE resource_allocation._rebuild_usages_active_claims + IS 'helper table for the rebuild_resource_usages_from_claims_for_resource_of_status method.'; + CREATE TABLE resource_allocation.conflict_reason ( id serial NOT NULL, reason text NOT NULL, @@ -350,6 +359,14 @@ CREATE INDEX resource_usage_resource_id_idx CREATE INDEX resource_usage_status_id_idx ON resource_allocation.resource_usage (status_id); +CREATE TABLE resource_allocation._rebuild_usages_active_usages ( LIKE resource_allocation.resource_usage INCLUDING INDEXES INCLUDING CONSTRAINTS ); +DROP INDEX resource_allocation._rebuild_usages_active_usages_status_id_idx; --remove unnecessary index +DROP INDEX resource_allocation._rebuild_usages_active_usages_resource_id_idx; --remove unnecessary index +ALTER TABLE resource_allocation._rebuild_usages_active_usages + OWNER TO resourceassignment; +COMMENT ON TABLE resource_allocation._rebuild_usages_active_usages + IS 'helper table for the rebuild_resource_usages_from_claims_for_resource_of_status method.'; + CREATE TABLE resource_monitoring.resource_availability ( id serial NOT NULL, resource_id integer NOT NULL REFERENCES virtual_instrument.resource ON DELETE CASCADE DEFERRABLE INITIALLY IMMEDIATE, diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/radb_performance_test.py b/SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/radb_performance_test.py new file mode 100755 index 00000000000..300e9707735 --- /dev/null +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/radb_performance_test.py @@ -0,0 +1,113 @@ +#!/usr/bin/python + +# Copyright (C) 2012-2015 ASTRON (Netherlands Institute for Radio Astronomy) +# P.O. Box 2, 7990 AA Dwingeloo, The Netherlands +# +# This file is part of the LOFAR software suite. +# The LOFAR software suite is free software: you can redistribute it and/or +# modify it under the terms of the GNU General Public License as published +# by the Free Software Foundation, either version 3 of the License, or +# (at your option) any later version. +# +# The LOFAR software suite is distributed in the hope that it will be useful, +# but WITHOUT ANY WARRANTY; without even the implied warranty of +# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the +# GNU General Public License for more details. +# +# You should have received a copy of the GNU General Public License along +# with the LOFAR software suite. If not, see <http://www.gnu.org/licenses/>. + +# $Id: $ +from optparse import OptionParser +import os +from datetime import datetime, timedelta +import logging +from random import randint + +logger = logging.getLogger(__name__) + +from lofar.common import dbcredentials +from lofar.sas.resourceassignment.database.radb import RADatabase +from lofar.common.datetimeutils import totalSeconds + +def test_resource_usages_performance(radb): + radb.updateResourceAvailability(117, available_capacity=10000000, total_capacity=10000000) + + now = datetime.utcnow() + now -= timedelta(minutes=now.minute, seconds=now.second, microseconds=now.microsecond) # round to full hour + spec_ids = [] + filename = 'resource_usages_performance%s.csv' % (datetime.utcnow().strftime('%Y%m%dT%H%M%S'),) + with open(filename, 'w') as file: + file.write('#claims, elapsed_insert, elapsed_rebuild\n') + counter = 0 + for k in range(20): + num_claims_to_insert = 20 + num_insert_repeats = 10 + elapsed_insert = 0 + for i in range(num_insert_repeats): + counter += 1 + result = radb.insertSpecificationAndTask(counter, counter, 'approved', 'observation', + now+timedelta(hours=3*counter), + now + timedelta(hours=1 + 3*counter), + 'content', 'CEP4') + task_id = result['task_id'] + task = radb.getTask(task_id) + spec_ids.append(task['specification_id']) + + claims = [{'resource_id': 117, + 'starttime': task['starttime']-timedelta(minutes=randint(0, 1800)), + 'endtime': task['starttime']+timedelta(seconds=randint(1801, 3600)), + 'status': 'tentative', + 'claim_size': q} + for q in range(num_claims_to_insert)] + + start = datetime.utcnow() + radb.insertResourceClaims(task_id, claims, 'foo', 1, 1) + elapsed_insert += totalSeconds(datetime.utcnow() - start) + elapsed_insert /= 10 + + start = datetime.utcnow() + # make sure the usage table is wiped, so asserts fail when rebuild_resource_usages_from_claims is erroneously roll'ed back. + radb.rebuild_resource_usages_from_claims(117, 'tentative') + elapsed_rebuild = totalSeconds(datetime.utcnow() - start) + + logger.info('TEST RESULT: radb now contains %d claims, insert of %d claims takes on average %.3fsec and a rebuild of the whole usage table takes %.3fsec', + len(radb.getResourceClaims()), num_claims_to_insert, elapsed_insert, elapsed_rebuild) + file.write('%d, %.3f, %.3f\n' % (len(radb.getResourceClaims()), elapsed_insert, elapsed_rebuild)) + file.flush() + + logger.info('removing all test specs/tasks/claims from db') + + for spec_id in spec_ids: + radb.deleteSpecification(spec_id) + + logger.info('Done. Results can be found in file: %s', filename) + +if __name__ == '__main__': + logging.basicConfig(format='%(asctime)s %(levelname)s %(message)s',level=logging.INFO) + + # Check the invocation arguments + parser = OptionParser("%prog [options]", description='runs some test queries on the radb') + parser.add_option('-V', '--verbose', dest='verbose', action='store_true', help='verbose logging') + parser.add_option_group(dbcredentials.options_group(parser)) + parser.set_defaults(dbcredentials="RADB") + (options, args) = parser.parse_args() + + dbcreds = dbcredentials.parse_options(options) + + print + print 'Using dbcreds: %s' % dbcreds.stringWithHiddenPassword() + print 'Are you sure you want to run the performance tests on this database? Tables will be modified! Precious data might be lost!' + print 'This test gives the most reproducable results when run on a clean database.' + print + answer = raw_input('CONTINUE? y/<n>: ') + if 'y' not in answer.lower(): + print 'Exiting without running the test...' + exit(1) + + print 'Starting test....' + radb = RADatabase(dbcreds=dbcreds, log_queries=options.verbose) + + test_resource_usages_performance(radb) + + diff --git a/SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/t_radb.py b/SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/t_radb.py index 4501170d430..c14737bf39c 100755 --- a/SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/t_radb.py +++ b/SAS/ResourceAssignment/ResourceAssignmentDatabase/tests/t_radb.py @@ -1291,7 +1291,7 @@ class ResourceAssignmentDatabaseTest(unittest.TestCase): #check that it's broken self.assertNotEqual(40, self.radb.get_max_resource_usage_between(117, task1['starttime'], task1['starttime'], 'claimed')['usage']) #fix it - self.radb.rebuild_resource_usages_table_from_claims() + self.radb.rebuild_resource_usages_from_claims() #and test again that it's ok self.assertEqual(40, self.radb.get_max_resource_usage_between(117, task1['starttime'], task1['starttime'], 'claimed')['usage']) self.assertEqual(0, self.radb.get_max_resource_usage_between(117, task1['starttime']-timedelta(hours=2), task1['starttime']-timedelta(hours=1), 'claimed')['usage']) @@ -1312,109 +1312,174 @@ class ResourceAssignmentDatabaseTest(unittest.TestCase): task = self.radb.getTask(task_id) self.assertTrue(task) + # insert a few claims one after the other, and check everything again and again in each intermediate step + # because there are various special cases coded below where claims overlap/touch/etc which all need to be checked. + # insert a claim, and check the usages for various timestamps claim1 = {'resource_id': 117, 'starttime': now+timedelta(minutes=0), 'endtime': now+timedelta(minutes=10), 'status': 'tentative', 'claim_size': 1} self.radb.insertResourceClaims(task_id, [claim1], 'foo', 1, 1) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) + # test usages twice, once to check the usages generated by insert-triggers, and then to check usages generated by rebuild_resource_usages_from_claims + for i in range(2): + if i == 1: + # make sure the usage table is wiped, so asserts fail when rebuild_resource_usages_from_claims is erroneously roll'ed back. + self.radb._executeQuery('TRUNCATE resource_allocation.resource_usage;') + self.radb.rebuild_resource_usages_from_claims(117, 'tentative') + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) # insert another non-overlapping claim, and check the usages for various timestamps claim2 = {'resource_id': 117, 'starttime': now+timedelta(minutes=20), 'endtime': now+timedelta(minutes=30), 'status': 'tentative', 'claim_size': 1} self.radb.insertResourceClaims(task_id, [claim2], 'foo', 1, 1) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) + # test usages twice, once to check the usages generated by insert-triggers, and then to check usages generated by rebuild_resource_usages_from_claims + for i in range(2): + if i == 1: + # make sure the usage table is wiped, so asserts fail when rebuild_resource_usages_from_claims is erroneously roll'ed back. + self.radb._executeQuery('TRUNCATE resource_allocation.resource_usage;') + self.radb.rebuild_resource_usages_from_claims(117, 'tentative') + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) # insert another claim which overlaps with both claim1 and claim2, and check the usages for various timestamps claim3 = {'resource_id': 117, 'starttime': now+timedelta(minutes=5), 'endtime': now+timedelta(minutes=25), 'status': 'tentative', 'claim_size': 1} self.radb.insertResourceClaims(task_id, [claim3], 'foo', 1, 1) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) - - # rebuild the usages table from scratch, and do same checks again - # (the rebuild method uses a different algorithm than the trigger methods after a claim-insert to build/update the usages table) - self.radb.rebuild_resource_usages_table_from_claims() - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) + # test usages twice, once to check the usages generated by insert-triggers, and then to check usages generated by rebuild_resource_usages_from_claims + for i in range(2): + if i == 1: + # make sure the usage table is wiped, so asserts fail when rebuild_resource_usages_from_claims is erroneously roll'ed back. + self.radb._executeQuery('TRUNCATE resource_allocation.resource_usage;') + self.radb.rebuild_resource_usages_from_claims(117, 'tentative') + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) + # insert another claim which overlaps with claim1 and ends at the same endtime as claim3, and check the usages for various timestamps claim4 = {'resource_id': 117, 'starttime': now+timedelta(minutes=7.5), 'endtime': claim3['endtime'], 'status': 'tentative', 'claim_size': 1} self.radb.insertResourceClaims(task_id, [claim4], 'foo', 1, 1) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) - self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim4['starttime'], 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) - self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) #c4_endtime should be equal to c3_endtime - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim4['endtime'], 'tentative')['usage']) #so usage should drop by 2*1 at this timestamp - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) + # test usages twice, once to check the usages generated by insert-triggers, and then to check usages generated by rebuild_resource_usages_from_claims + for i in range(2): + if i == 1: + # make sure the usage table is wiped, so asserts fail when rebuild_resource_usages_from_claims is erroneously roll'ed back. + self.radb._executeQuery('TRUNCATE resource_allocation.resource_usage;') + self.radb.rebuild_resource_usages_from_claims(117, 'tentative') + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim4['starttime'], 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) #c4_endtime should be equal to c3_endtime + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim4['endtime'], 'tentative')['usage']) #so usage should drop by 2*1 at this timestamp + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) # insert another claim which starts when claim1 ends and last 1 minute, and check the usages for various timestamps claim5 = {'resource_id': 117, 'starttime': claim1['endtime'], 'endtime': claim1['endtime']+timedelta(minutes=1), 'status': 'tentative', 'claim_size': 1} self.radb.insertResourceClaims(task_id, [claim5], 'foo', 1, 1) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) - self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim4['starttime'], 'tentative')['usage']) - self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) #drops by 1 because c1 ends, but climbs by 1 because c5 starts - self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim5['starttime'], 'tentative')['usage']) #drops by 1 because c1 ends, but climbs by 1 because c5 starts - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim5['endtime'], 'tentative')['usage']) #drops by 1 because c5 ends - self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) - self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim4['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) + # test usages twice, once to check the usages generated by insert-triggers, and then to check usages generated by rebuild_resource_usages_from_claims + for i in range(2): + if i == 1: + # make sure the usage table is wiped, so asserts fail when rebuild_resource_usages_from_claims is erroneously roll'ed back. + self.radb._executeQuery('TRUNCATE resource_allocation.resource_usage;') + self.radb.rebuild_resource_usages_from_claims(117, 'tentative') + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim4['starttime'], 'tentative')['usage']) + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) #drops by 1 because c1 ends, but climbs by 1 because c5 starts + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim5['starttime'], 'tentative')['usage']) #drops by 1 because c1 ends, but climbs by 1 because c5 starts + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim5['endtime'], 'tentative')['usage']) #drops by 1 because c5 ends + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim4['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) # last edge case, insert another claim which starts when first claim starts, and end when last claim ends. Should lift all usages by 1 (except outer ones). claim6 = {'resource_id': 117, 'starttime': claim1['starttime'], 'endtime': claim2['endtime'], 'status': 'tentative', 'claim_size': 1} self.radb.insertResourceClaims(task_id, [claim6], 'foo', 1, 1) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) - self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) - self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim4['starttime'], 'tentative')['usage']) - self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) - self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim5['starttime'], 'tentative')['usage']) - self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim5['endtime'], 'tentative')['usage']) - self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) #c4_endtime should be equal to c3_endtime - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim4['endtime'], 'tentative')['usage']) #so usage should drop by 2*1 at this timestamp - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) - - # and finally, again, rebuild the usages table from scratch, and do same checks again - # (the rebuild method uses a different algorithm than the trigger methods after a claim-insert to build/update the usages table) - self.radb.rebuild_resource_usages_table_from_claims() - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) - self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) - self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim4['starttime'], 'tentative')['usage']) - self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) - self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim5['starttime'], 'tentative')['usage']) - self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim5['endtime'], 'tentative')['usage']) - self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) #c4_endtime should be equal to c3_endtime - self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim4['endtime'], 'tentative')['usage']) #so usage should drop by 2*1 at this timestamp - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) - self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) + # test usages twice, once to check the usages generated by insert-triggers, and then to check usages generated by rebuild_resource_usages_from_claims + for i in range(2): + if i == 1: + # make sure the usage table is wiped, so asserts fail when rebuild_resource_usages_from_claims is erroneously roll'ed back. + self.radb._executeQuery('TRUNCATE resource_allocation.resource_usage;') + self.radb.rebuild_resource_usages_from_claims(117, 'tentative') + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim4['starttime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim5['starttime'], 'tentative')['usage']) + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim5['endtime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) #c4_endtime should be equal to c3_endtime + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim4['endtime'], 'tentative')['usage']) #so usage should drop by 2*1 at this timestamp + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) + + # conclude with two simple cases, + # first final simple case: insert another claim follows (non overlapping/non-touching) all others + claim7 = {'resource_id': 117, 'starttime': claim2['endtime']+timedelta(minutes=10), 'endtime': claim2['endtime']+timedelta(minutes=20), 'status': 'tentative', 'claim_size': 1} + self.radb.insertResourceClaims(task_id, [claim7], 'foo', 1, 1) + # test usages twice, once to check the usages generated by insert-triggers, and then to check usages generated by rebuild_resource_usages_from_claims + for i in range(2): + if i == 1: + # make sure the usage table is wiped, so asserts fail when rebuild_resource_usages_from_claims is erroneously roll'ed back. + logger.info('') + self.radb._executeQuery('TRUNCATE resource_allocation.resource_usage;') + self.radb.rebuild_resource_usages_from_claims(117, 'tentative') + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=10), 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim4['starttime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim5['starttime'], 'tentative')['usage']) + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim5['endtime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim4['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim7['starttime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim7['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) + + # second final simple case: insert another claim which precedes (non overlapping/non-touching) all the others + claim8 = {'resource_id': 117, 'starttime': claim1['starttime']-timedelta(minutes=20), 'endtime': claim1['starttime']-timedelta(minutes=10), 'status': 'tentative', 'claim_size': 1} + self.radb.insertResourceClaims(task_id, [claim8], 'foo', 1, 1) + # test usages twice, once to check the usages generated by insert-triggers, and then to check usages generated by rebuild_resource_usages_from_claims + for i in range(2): + if i == 1: + # make sure the usage table is wiped, so asserts fail when rebuild_resource_usages_from_claims is erroneously roll'ed back. + self.radb._executeQuery('TRUNCATE resource_allocation.resource_usage;') + self.radb.rebuild_resource_usages_from_claims(117, 'tentative') + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now-timedelta(minutes=100), 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim8['starttime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim8['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim1['starttime']-timedelta(minutes=1), 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim1['starttime'], 'tentative')['usage']) + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim3['starttime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim4['starttime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim1['endtime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim5['starttime'], 'tentative')['usage']) + self.assertEqual( 3, self.radb.get_resource_usage_at_or_before(117, claim5['endtime'], 'tentative')['usage']) + self.assertEqual( 4, self.radb.get_resource_usage_at_or_before(117, claim2['starttime'], 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim3['endtime'], 'tentative')['usage']) + self.assertEqual( 2, self.radb.get_resource_usage_at_or_before(117, claim4['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim2['endtime'], 'tentative')['usage']) + self.assertEqual( 1, self.radb.get_resource_usage_at_or_before(117, claim7['starttime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, claim7['endtime'], 'tentative')['usage']) + self.assertEqual( 0, self.radb.get_resource_usage_at_or_before(117, now+timedelta(minutes=1000), 'tentative')['usage']) def test_overlapping_claims(self): # this is a special testcase to prove a bug found at 2017-08-16 -- GitLab