diff --git a/SAS/TMSS/backend/src/tmss/tmssapp/migrations/0023_patches.py b/SAS/TMSS/backend/src/tmss/tmssapp/migrations/0023_patches.py
new file mode 100644
index 0000000000000000000000000000000000000000..d9543dea46ef82e11ac30a98e6fffb4528f62485
--- /dev/null
+++ b/SAS/TMSS/backend/src/tmss/tmssapp/migrations/0023_patches.py
@@ -0,0 +1,168 @@
+from django.db import migrations, models
+import django.db.models.deletion
+from lofar.sas.tmss.tmss.tmssapp.populate import populate_task_schedulingunit_choices
+
+
+class Migration(migrations.Migration):
+
+    dependencies = [
+        ('tmssapp', '0022_sip'),
+    ]
+
+    operations = [
+        # the following migration step alters the tmssapp_taskblueprint_compute_aggretates_for_schedulingunitblueprint trigger function from migration 0015_db_aggregates
+        # the only difference is that there is a patch in assigning the scheduling unit 'ingested' status.
+        # 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)
+                   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'))
+                   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)
+                   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')) 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')) 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') 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') 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;
+
+                   -- default when no tasks available
+                   IF agg_status IS NULL THEN
+                       agg_status := 'schedulable';
+                   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();
+             '''),
+
+        # use database triggers to block updates on blueprint tables for immutable fields
+        # this one overrides the trigger from 0019_schedulingunitblueprint_immutable_fields.py
+        migrations.RunSQL('''CREATE OR REPLACE FUNCTION tmssapp_block_scheduling_unit_blueprint_immutable_fields_update()
+                          RETURNS trigger AS
+                          $BODY$
+                          BEGIN
+                            IF OLD.specifications_template_id <> NEW.specifications_template_id OR
+                               OLD.name <> NEW.name OR
+                               OLD.description <> NEW.description OR
+                               (OLD.ingest_permission_granted_since IS NOT NULL AND OLD.ingest_permission_granted_since <> NEW.ingest_permission_granted_since) OR
+                               OLD.ingest_permission_required <> NEW.ingest_permission_required OR
+                               OLD.piggyback_allowed_tbb <> NEW.piggyback_allowed_tbb OR
+                               OLD.piggyback_allowed_aartfaac <> NEW.piggyback_allowed_aartfaac THEN
+                              RAISE EXCEPTION 'ILLEGAL UPDATE OF IMMUTABLE BLUEPRINT FIELD';
+                            END IF;
+                            IF (OLD.scheduling_constraints_template_id <> NEW.scheduling_constraints_template_id OR
+                                OLD.scheduling_constraints_doc <> NEW.scheduling_constraints_doc) AND
+                                OLD.status_id NOT IN ('defined', 'schedulable', 'unschedulable', 'scheduled') THEN
+                              RAISE EXCEPTION 'ILLEGAL UPDATE OF IMMUTABLE scheduling_constraints FIELD for status=%', OLD.status_id;
+                            END IF;
+                          RETURN NEW;
+                          END;
+                          $BODY$
+                          LANGUAGE plpgsql VOLATILE;
+                          DROP TRIGGER IF EXISTS tmssapp_block_scheduling_unit_blueprint_immutable_fields_update ON tmssapp_SchedulingUnitBlueprint ;
+                          CREATE TRIGGER tmssapp_block_scheduling_unit_blueprint_immutable_fields_update
+                          BEFORE UPDATE ON tmssapp_SchedulingUnitBlueprint
+                          FOR EACH ROW EXECUTE PROCEDURE tmssapp_block_scheduling_unit_blueprint_immutable_fields_update();
+                          ''')             
+             
+    ]