From 56dc5800551d1fb2ddcdec87d56781a1ed69066a Mon Sep 17 00:00:00 2001 From: Jorrit Schaap <schaap@astron.nl> Date: Fri, 5 Jan 2024 11:51:56 +0100 Subject: [PATCH] TMSS-2879: bug fix --- .../0052_bugfix_unit_status_aggregates.py | 154 ++++++++++++++++++ 1 file changed, 154 insertions(+) create mode 100644 SAS/TMSS/backend/src/tmss/tmssapp/migrations/0052_bugfix_unit_status_aggregates.py diff --git a/SAS/TMSS/backend/src/tmss/tmssapp/migrations/0052_bugfix_unit_status_aggregates.py b/SAS/TMSS/backend/src/tmss/tmssapp/migrations/0052_bugfix_unit_status_aggregates.py new file mode 100644 index 00000000000..735fc51196f --- /dev/null +++ b/SAS/TMSS/backend/src/tmss/tmssapp/migrations/0052_bugfix_unit_status_aggregates.py @@ -0,0 +1,154 @@ + + +from django.db import migrations + +from lofar.sas.tmss.tmss.tmssapp.populate import populate_on_hold_status_and_transitions + + +class Migration(migrations.Migration): + + dependencies = [ + ('tmssapp', '0051_cyclereport_projects'), + ] + + operations = [ + # the following migration step alters the tmssapp_taskblueprint_compute_aggretates_for_schedulingunitblueprint trigger function from migration 0037_populate_subtask_allowed_state_transitions_on_hold.py + # the only difference is that the state for all-tasks-obsolete is now aggregated as well. + # yes, this is ugly/annoying that we have to replicate code, but that's how database migration steps/deltas/patches work... + migrations.RunSQL('''CREATE OR REPLACE FUNCTION tmssapp_taskblueprint_compute_aggretates_for_schedulingunitblueprint() + RETURNS trigger AS + $BODY$ + DECLARE + agg_scheduled_start_time timestamp with time zone; + agg_scheduled_stop_time timestamp with time zone; + agg_actual_process_start_time timestamp with time zone; + agg_actual_process_stop_time timestamp with time zone; + agg_actual_on_sky_start_time timestamp with time zone; + agg_actual_on_sky_stop_time timestamp with time zone; + agg_process_start_time timestamp with time zone; + agg_process_stop_time timestamp with time zone; + agg_on_sky_start_time timestamp with time zone; + agg_on_sky_stop_time timestamp with time zone; + agg_observed_start_time timestamp with time zone; + agg_observed_stop_time timestamp with time zone; + agg_status character varying(128); + agg_obsolete_since timestamp with time zone; + agg_on_sky_duration interval; + agg_observed_duration interval; + agg_duration interval; + BEGIN + + -- aggregate the various timestamps + -- consider all the tasks for this schedulingunitblueprint + -- use a WITH Common Table Expression followed by a SELECT INTO variables for speed + WITH task_agg AS (SELECT MIN(scheduled_start_time) as scheduled_start_time, + MAX(scheduled_stop_time) as scheduled_stop_time, + MIN(actual_process_start_time) as actual_process_start_time, + MAX(actual_process_stop_time) as actual_process_stop_time, + SUM(duration) as duration, + MIN(actual_on_sky_start_time) as actual_on_sky_start_time, + MAX(actual_on_sky_stop_time) as actual_on_sky_stop_time, + MIN(process_start_time) as process_start_time, + MAX(process_stop_time) as process_stop_time, + MIN(on_sky_start_time) as on_sky_start_time, + MAX(on_sky_stop_time) as on_sky_stop_time, + SUM(on_sky_duration) as on_sky_duration, + MIN(obsolete_since) as obsolete_since + FROM tmssapp_taskblueprint + WHERE tmssapp_taskblueprint.scheduling_unit_blueprint_id=NEW.scheduling_unit_blueprint_id + AND tmssapp_taskblueprint.obsolete_since IS NULL) + SELECT scheduled_start_time, scheduled_stop_time, actual_process_start_time, actual_process_stop_time, actual_on_sky_start_time, actual_on_sky_stop_time, on_sky_start_time, on_sky_stop_time, process_start_time, process_stop_time, on_sky_start_time, on_sky_stop_time, obsolete_since, duration, on_sky_duration + INTO agg_scheduled_start_time, agg_scheduled_stop_time, agg_actual_process_start_time, agg_actual_process_stop_time, agg_actual_on_sky_start_time, agg_actual_on_sky_stop_time, agg_on_sky_start_time, agg_on_sky_stop_time, agg_process_start_time, agg_process_stop_time, agg_on_sky_start_time, agg_on_sky_stop_time, agg_obsolete_since, agg_duration, agg_on_sky_duration + FROM task_agg; + + -- compute observed_start/stop_time observerd_duration. These are derived from finished/observed tasks only. + -- use a WITH Common Table Expression followed by a SELECT INTO variables for speed + WITH observed_task_agg AS (SELECT MIN(on_sky_start_time) as observed_start_time, + MAX(on_sky_stop_time) as observed_stop_time, + SUM(on_sky_duration) as observed_duration + FROM tmssapp_taskblueprint + WHERE tmssapp_taskblueprint.scheduling_unit_blueprint_id=NEW.scheduling_unit_blueprint_id + AND tmssapp_taskblueprint.status_id in ('observed', 'finished') + AND tmssapp_taskblueprint.obsolete_since IS NULL) + SELECT observed_start_time, observed_stop_time, observed_duration + INTO agg_observed_start_time, agg_observed_stop_time, agg_observed_duration + FROM observed_task_agg; + + -- aggregate the task statuses into one schedulingunit status + -- See design: https://support.astron.nl/confluence/display/TMSS/Specification+Flow/#SpecificationFlow-SchedulingUnitBlueprints + -- consider all the taskblueprints for this schedulingunitblueprint + -- use a WITH Common Table Expression followed by a SELECT INTO variables for speed + WITH task_statuses AS (SELECT tmssapp_taskblueprint.status_id, tmssapp_tasktemplate.type_id + FROM tmssapp_taskblueprint + INNER JOIN tmssapp_tasktemplate on tmssapp_tasktemplate.id=tmssapp_taskblueprint.specifications_template_id + WHERE tmssapp_taskblueprint.scheduling_unit_blueprint_id=NEW.scheduling_unit_blueprint_id + AND tmssapp_taskblueprint.obsolete_since IS NULL) + SELECT CASE + WHEN (SELECT COUNT(true) FROM task_statuses)=0 THEN 'defined' + WHEN EXISTS(SELECT true FROM task_statuses WHERE status_id='defined') THEN 'defined' + WHEN (SELECT COUNT(true) FROM task_statuses WHERE status_id in ('finished', 'observed'))=(SELECT COUNT(true) FROM task_statuses) THEN 'finished' + WHEN EXISTS(SELECT true FROM task_statuses WHERE status_id='cancelled') THEN 'cancelled' + WHEN EXISTS(SELECT true FROM task_statuses WHERE status_id='error') THEN 'error' + WHEN EXISTS(SELECT true FROM task_statuses WHERE status_id='unschedulable') THEN 'unschedulable' + WHEN EXISTS(SELECT true FROM task_statuses WHERE status_id IN ('queued', 'started', 'observed', 'finished', 'on hold')) THEN + CASE + WHEN (SELECT COUNT(true) FROM task_statuses WHERE type_id='observation' AND status_id IN ('observed', 'finished'))<(SELECT COUNT(true) FROM task_statuses WHERE type_id='observation') THEN 'observing' + WHEN NOT EXISTS(SELECT true FROM task_statuses WHERE type_id='pipeline' AND status_id IN ('queued', 'started', 'finished')) THEN 'observed' + WHEN EXISTS(SELECT true FROM task_statuses WHERE type_id='ingest' AND status_id IN ('queued', 'started', 'on hold')) THEN 'ingesting' + WHEN (SELECT COUNT(true) FROM task_statuses WHERE type_id='ingest' AND status_id='finished')=(SELECT COUNT(true) FROM task_statuses WHERE type_id='ingest') AND (SELECT COUNT(true) FROM task_statuses WHERE type_id='ingest')>0 THEN 'ingested' + WHEN (SELECT COUNT(true) FROM task_statuses WHERE type_id='pipeline' AND status_id='finished')=(SELECT COUNT(true) FROM task_statuses WHERE type_id='pipeline') AND (SELECT COUNT(true) FROM task_statuses WHERE type_id='pipeline')>0 THEN 'processed' + WHEN EXISTS(SELECT true FROM task_statuses WHERE type_id='pipeline' AND status_id IN ('queued', 'started', 'scheduled', 'finished')) THEN 'processing' + END + WHEN EXISTS(SELECT true FROM task_statuses WHERE status_id='scheduled') THEN 'scheduled' + END + INTO agg_status + FROM task_statuses; + + -- when no non-obsolete tasks available + IF agg_status IS NULL THEN + -- when no tasks at all -> defined + IF (SELECT COUNT(tmssapp_taskblueprint.id) FROM tmssapp_taskblueprint WHERE tmssapp_taskblueprint.scheduling_unit_blueprint_id=NEW.scheduling_unit_blueprint_id) = 0 THEN + agg_status := 'defined'; + ELSE + -- there are tasks. + -- if all obsolete -> cancelled + IF (SELECT COUNT(tmssapp_taskblueprint.id) FROM tmssapp_taskblueprint WHERE tmssapp_taskblueprint.scheduling_unit_blueprint_id=NEW.scheduling_unit_blueprint_id AND tmssapp_taskblueprint.obsolete_since IS NOT NULL)=(SELECT COUNT(tmssapp_taskblueprint.id) FROM tmssapp_taskblueprint WHERE tmssapp_taskblueprint.scheduling_unit_blueprint_id=NEW.scheduling_unit_blueprint_id) THEN + agg_status := 'cancelled'; + ELSE + agg_status := 'schedulable'; + END IF; + END IF; + END IF; + + -- all aggregated timestamps and statuses were computed + -- now update the referred taskblueprint with these aggregated values + UPDATE tmssapp_schedulingunitblueprint + SET scheduled_start_time=agg_scheduled_start_time, + scheduled_stop_time=agg_scheduled_stop_time, + actual_process_start_time=agg_actual_process_start_time, + actual_process_stop_time=agg_actual_process_stop_time, + actual_on_sky_start_time=agg_actual_on_sky_start_time, + actual_on_sky_stop_time=agg_actual_on_sky_stop_time, + process_start_time=agg_process_start_time, + process_stop_time=agg_process_stop_time, + on_sky_start_time=agg_on_sky_start_time, + on_sky_stop_time=agg_on_sky_stop_time, + observed_start_time=agg_observed_start_time, + observed_stop_time=agg_observed_stop_time, + status_id=agg_status, + obsolete_since=agg_obsolete_since, + on_sky_duration=agg_on_sky_duration, + observed_duration=agg_observed_duration, + duration=agg_duration + WHERE id=NEW.scheduling_unit_blueprint_id; + RETURN NEW; + END; + $BODY$ + LANGUAGE plpgsql VOLATILE; + DROP TRIGGER IF EXISTS tmssapp_taskblueprint_compute_aggretates_for_schedulingunitblueprint ON tmssapp_taskblueprint ; + CREATE TRIGGER tmssapp_taskblueprint_compute_aggretates_for_schedulingunitblueprint + AFTER INSERT OR UPDATE ON tmssapp_taskblueprint + FOR EACH ROW EXECUTE PROCEDURE tmssapp_taskblueprint_compute_aggretates_for_schedulingunitblueprint(); + '''), + ] + -- GitLab