diff --git a/deployment/merge_aerie_db/merge_db/migrate_scheduler.sql b/deployment/merge_aerie_db/merge_db/migrate_scheduler.sql index 5861c4dc12..81c86530ee 100644 --- a/deployment/merge_aerie_db/merge_db/migrate_scheduler.sql +++ b/deployment/merge_aerie_db/merge_db/migrate_scheduler.sql @@ -13,19 +13,43 @@ alter table metadata.scheduling_goal_definition_tags set schema tags; -- Metadata Schema is empty now drop schema metadata; --- Update Foreign Keys +-- Update function definitions +\! echo 'Migrating Scheduler Triggers...' +\ir migrate_scheduler_triggers.sql +\! echo 'Done!' + +-- Add Tags Foreign Keys, removing orphan entries first +delete from tags.scheduling_condition_tags + where not exists( + select from tags.tags t + where tag_id = t.id); alter table tags.scheduling_condition_tags add foreign key (tag_id) references tags.tags on update cascade on delete cascade; + +delete from tags.scheduling_condition_definition_tags + where not exists( + select from tags.tags t + where tag_id = t.id); alter table tags.scheduling_condition_definition_tags add foreign key (tag_id) references tags.tags on update cascade on delete cascade; + +delete from tags.scheduling_goal_tags + where not exists( + select from tags.tags t + where tag_id = t.id); alter table tags.scheduling_goal_tags add foreign key (tag_id) references tags.tags on update cascade on delete cascade; + +delete from tags.scheduling_goal_definition_tags + where not exists( + select from tags.tags t + where tag_id = t.id); alter table tags.scheduling_goal_definition_tags add foreign key (tag_id) references tags.tags on update cascade @@ -46,7 +70,17 @@ execute function scheduler.notify_scheduling_workers_cancel(); drop type scheduler.status_t; --- Add new constraints +-- Add new constraints, handling orphans first +update scheduler.scheduling_request + set dataset_id = null + where not exists( + select from merlin.dataset d + where dataset_id = d.id); +update scheduler.scheduling_request + set requested_by = null + where not exists( + select from permissions.users u + where requested_by = u.username); alter table scheduler.scheduling_request add constraint scheduling_request_requester_exists foreign key (requested_by) @@ -59,28 +93,59 @@ add constraint scheduling_request_references_dataset on update cascade on delete set null; +delete from scheduler.scheduling_model_specification_conditions + where not exists( + select from merlin.mission_model m + where model_id = m.id); alter table scheduler.scheduling_model_specification_conditions add foreign key (model_id) references merlin.mission_model on update cascade on delete cascade; + +delete from scheduler.scheduling_model_specification_goals + where not exists( + select from merlin.mission_model m + where model_id = m.id); alter table scheduler.scheduling_model_specification_goals add foreign key (model_id) references merlin.mission_model on update cascade on delete cascade; + +delete from scheduler.scheduling_specification + where not exists( + select from merlin.plan p + where plan_id = p.id); alter table scheduler.scheduling_specification add constraint scheduling_spec_plan_id_fkey foreign key (plan_id) references merlin.plan on update cascade on delete cascade; + +update scheduler.scheduling_condition_definition + set author = null + where not exists( + select from permissions.users u + where author = u.username); alter table scheduler.scheduling_condition_definition add constraint condition_definition_author_exists foreign key (author) references permissions.users on update cascade on delete set null; + +update scheduler.scheduling_condition_metadata + set owner = null + where not exists( + select from permissions.users u + where owner = u.username); +update scheduler.scheduling_condition_metadata + set updated_by = null + where not exists( + select from permissions.users u + where updated_by = u.username); alter table scheduler.scheduling_condition_metadata add constraint condition_owner_exists foreign key (owner) @@ -92,12 +157,29 @@ add constraint condition_updated_by_exists references permissions.users on update cascade on delete set null; + +update scheduler.scheduling_goal_definition + set author = null + where not exists( + select from permissions.users u + where author = u.username); alter table scheduler.scheduling_goal_definition add constraint goal_definition_author_exists foreign key (author) references permissions.users on update cascade on delete set null; + +update scheduler.scheduling_goal_metadata + set owner = null + where not exists( + select from permissions.users u + where owner = u.username); +update scheduler.scheduling_goal_metadata + set updated_by = null + where not exists( + select from permissions.users u + where updated_by = u.username); alter table scheduler.scheduling_goal_metadata add constraint goal_owner_exists foreign key (owner) diff --git a/deployment/merge_aerie_db/merge_db/migrate_scheduler_functions.sql b/deployment/merge_aerie_db/merge_db/migrate_scheduler_functions.sql index 05288f7263..6b59f77a11 100644 --- a/deployment/merge_aerie_db/merge_db/migrate_scheduler_functions.sql +++ b/deployment/merge_aerie_db/merge_db/migrate_scheduler_functions.sql @@ -1,63 +1,4 @@ begin; ---------------------- --- UPDATE TRIGGERS -- ---------------------- -create or replace trigger increment_revision_on_update_trigger - before update on scheduler.scheduling_specification - for each row - when (pg_trigger_depth() < 1) - execute function util_functions.increment_revision_update(); -drop function scheduler.increment_revision_on_update(); - -create or replace trigger set_timestamp -before update on scheduler.scheduling_condition_metadata -for each row -execute function util_functions.set_updated_at(); -drop function scheduler.scheduling_condition_metadata_set_updated_at(); - -create or replace trigger set_timestamp -before update on scheduler.scheduling_goal_metadata -for each row -execute function util_functions.set_updated_at(); -drop function scheduler.scheduling_goal_metadata_set_updated_at(); - -create function scheduler.create_scheduling_spec_for_new_plan() -returns trigger -security definer -language plpgsql as $$ -declare - spec_id integer; -begin - -- Create a new scheduling specification - insert into scheduler.scheduling_specification (revision, plan_id, plan_revision, horizon_start, horizon_end, - simulation_arguments, analysis_only) - values (0, new.id, new.revision, new.start_time, new.start_time+new.duration, '{}', false) - returning id into spec_id; - - -- Populate the scheduling specification - insert into scheduler.scheduling_specification_goals (specification_id, goal_id, goal_revision, priority) - select spec_id, msg.goal_id, msg.goal_revision, msg.priority - from scheduler.scheduling_model_specification_goals msg - where msg.model_id = new.model_id; - - insert into scheduler.scheduling_specification_conditions (specification_id, condition_id, condition_revision) - select spec_id, msc.condition_id, msc.condition_revision - from scheduler.scheduling_model_specification_conditions msc - where msc.model_id = new.model_id; - - return new; -end -$$; - -comment on function scheduler.create_scheduling_spec_for_new_plan() is e'' -'Creates a scheduling specification for a new plan - and populates it with the contents of the plan''s model''s specification.'; - -create trigger scheduling_spec_for_new_plan_trigger -after insert on merlin.plan -for each row -execute function scheduler.create_scheduling_spec_for_new_plan(); - --------------------------------- -- UPDATE FUNCTION DEFINITIONS -- --------------------------------- diff --git a/deployment/merge_aerie_db/merge_db/migrate_scheduler_triggers.sql b/deployment/merge_aerie_db/merge_db/migrate_scheduler_triggers.sql new file mode 100644 index 0000000000..551e5e655e --- /dev/null +++ b/deployment/merge_aerie_db/merge_db/migrate_scheduler_triggers.sql @@ -0,0 +1,60 @@ +begin; +--------------------- +-- UPDATE TRIGGERS -- +--------------------- +create or replace trigger increment_revision_on_update_trigger + before update on scheduler.scheduling_specification + for each row + when (pg_trigger_depth() < 1) + execute function util_functions.increment_revision_update(); +drop function scheduler.increment_revision_on_update(); + +create or replace trigger set_timestamp +before update on scheduler.scheduling_condition_metadata +for each row +execute function util_functions.set_updated_at(); +drop function scheduler.scheduling_condition_metadata_set_updated_at(); + +create or replace trigger set_timestamp +before update on scheduler.scheduling_goal_metadata +for each row +execute function util_functions.set_updated_at(); +drop function scheduler.scheduling_goal_metadata_set_updated_at(); + +create function scheduler.create_scheduling_spec_for_new_plan() +returns trigger +security definer +language plpgsql as $$ +declare + spec_id integer; +begin + -- Create a new scheduling specification + insert into scheduler.scheduling_specification (revision, plan_id, plan_revision, horizon_start, horizon_end, + simulation_arguments, analysis_only) + values (0, new.id, new.revision, new.start_time, new.start_time+new.duration, '{}', false) + returning id into spec_id; + + -- Populate the scheduling specification + insert into scheduler.scheduling_specification_goals (specification_id, goal_id, goal_revision, priority) + select spec_id, msg.goal_id, msg.goal_revision, msg.priority + from scheduler.scheduling_model_specification_goals msg + where msg.model_id = new.model_id; + + insert into scheduler.scheduling_specification_conditions (specification_id, condition_id, condition_revision) + select spec_id, msc.condition_id, msc.condition_revision + from scheduler.scheduling_model_specification_conditions msc + where msc.model_id = new.model_id; + + return new; +end +$$; + +comment on function scheduler.create_scheduling_spec_for_new_plan() is e'' +'Creates a scheduling specification for a new plan + and populates it with the contents of the plan''s model''s specification.'; + +create trigger scheduling_spec_for_new_plan_trigger +after insert on merlin.plan +for each row +execute function scheduler.create_scheduling_spec_for_new_plan(); +end; diff --git a/deployment/merge_aerie_db/merge_db/migrate_sequencing.sql b/deployment/merge_aerie_db/merge_db/migrate_sequencing.sql index 6813b15618..8ed61cd5cc 100644 --- a/deployment/merge_aerie_db/merge_db/migrate_sequencing.sql +++ b/deployment/merge_aerie_db/merge_db/migrate_sequencing.sql @@ -9,16 +9,58 @@ alter table metadata.expansion_rule_tags set schema tags; -- Metadata Schema is empty now drop schema metadata; --- Update Foreign Keys +-- Update Triggers +drop trigger set_timestamp on sequencing.expansion_rule; +drop function sequencing.expansion_rule_set_updated_at(); + +create trigger set_timestamp +before update on sequencing.expansion_rule +for each row +execute function util_functions.set_updated_at(); + +drop trigger set_timestamp on sequencing.user_sequence; +drop function sequencing.user_sequence_set_updated_at(); + +create trigger set_timestamp +before update on sequencing.user_sequence +for each row +execute function util_functions.set_updated_at(); + +-- Update Foreign Keys, handling orphans first +delete from tags.expansion_rule_tags + where not exists( + select from tags.tags t + where tag_id = t.id); alter table tags.expansion_rule_tags add foreign key (tag_id) references tags.tags on update cascade on delete cascade; + +delete from sequencing.expanded_sequences + where not exists( + select from merlin.simulation_dataset sd + where simulation_dataset_id = sd.id); alter table sequencing.expanded_sequences add constraint expanded_sequences_to_sim_run foreign key (simulation_dataset_id) references merlin.simulation_dataset on delete cascade; + +update sequencing.expansion_rule + set authoring_mission_model_id = null + where not exists( + select from merlin.mission_model m + where authoring_mission_model_id = m.id); +update sequencing.expansion_rule + set owner = null + where not exists( + select from permissions.users u + where owner = u.username); +update sequencing.expansion_rule + set updated_by = null + where not exists( + select from permissions.users u + where updated_by = u.username); alter table sequencing.expansion_rule add foreign key (authoring_mission_model_id) references merlin.mission_model @@ -35,10 +77,29 @@ alter table sequencing.expansion_rule comment on column sequencing.expansion_rule.activity_type is e'' 'The activity type this expansion rule applies to. This type is not model-specific.'; +delete from sequencing.expansion_run + where not exists( + select from merlin.simulation_dataset sd + where simulation_dataset_id = sd.id); alter table sequencing.expansion_run add foreign key (simulation_dataset_id) references merlin.simulation_dataset on delete cascade; + +delete from sequencing.expansion_set + where not exists( + select from merlin.mission_model m + where mission_model_id = m.id); +update sequencing.expansion_set + set owner = null + where not exists( + select from permissions.users u + where owner = u.username); +update sequencing.expansion_set + set updated_by = null + where not exists( + select from permissions.users u + where updated_by = u.username); alter table sequencing.expansion_set add foreign key (mission_model_id) references merlin.mission_model @@ -51,15 +112,35 @@ alter table sequencing.expansion_set references permissions.users on update cascade on delete set null; + +delete from sequencing.sequence + where not exists( + select from merlin.simulation_dataset sd + where simulation_dataset_id = sd.id); alter table sequencing.sequence add foreign key (simulation_dataset_id) references merlin.simulation_dataset on delete cascade; + +delete from sequencing.sequence_to_simulated_activity + where not exists( + select from merlin.simulation_dataset sd + where simulation_dataset_id = sd.id); alter table sequencing.sequence_to_simulated_activity add constraint sequence_to_sim_run foreign key (simulation_dataset_id) references merlin.simulation_dataset on delete cascade; + +delete from sequencing.user_sequence + where not exists( + select from sequencing.command_dictionary cd + where authoring_command_dict_id = cd.id); +update sequencing.user_sequence + set owner = null + where not exists( + select from permissions.users u + where owner = u.username); alter table sequencing.user_sequence add foreign key (authoring_command_dict_id) references sequencing.command_dictionary @@ -69,23 +150,6 @@ alter table sequencing.user_sequence on update cascade on delete cascade; --- Update Triggers -drop trigger set_timestamp on sequencing.expansion_rule; -drop function sequencing.expansion_rule_set_updated_at(); - -create trigger set_timestamp -before update on sequencing.expansion_rule -for each row -execute function util_functions.set_updated_at(); - -drop trigger set_timestamp on sequencing.user_sequence; -drop function sequencing.user_sequence_set_updated_at(); - -create trigger set_timestamp -before update on sequencing.user_sequence -for each row -execute function util_functions.set_updated_at(); - -- Update Views create or replace view sequencing.expansion_set_rule_view as select str.set_id, diff --git a/deployment/merge_aerie_db/merge_db/migrate_ui.sql b/deployment/merge_aerie_db/merge_db/migrate_ui.sql index 27e16b84f4..3de5ea63ab 100644 --- a/deployment/merge_aerie_db/merge_db/migrate_ui.sql +++ b/deployment/merge_aerie_db/merge_db/migrate_ui.sql @@ -8,35 +8,51 @@ comment on schema public is 'standard public schema'; -- Add PGCrypto back to "public" create extension pgcrypto with schema public; --- Add Missing FKeys +-- Update Triggers +drop trigger extensions_set_timestamp on ui.extensions; +drop function ui.extensions_set_updated_at(); +create trigger extensions_set_timestamp + before update on ui.extensions + for each row +execute function util_functions.set_updated_at(); + +drop trigger set_timestamp on ui.view; +drop function ui.view_set_updated_at(); +create trigger set_timestamp +before update on ui.view +for each row +execute function util_functions.set_updated_at(); + +-- Add Missing FKeys, Handling Orphans First +delete from ui.extension_roles er + where not exists( + select from permissions.user_roles ur + where er.role = ur.role); alter table ui.extension_roles add foreign key (role) references permissions.user_roles (role) on update cascade on delete cascade; + +update ui.extensions + set owner = null + where not exists( + select from permissions.users u + where owner = u.username); alter table ui.extensions add foreign key (owner) references permissions.users (username) on update cascade on delete set null; + +update ui.view + set owner = null + where not exists( + select from permissions.users u + where owner = u.username); alter table ui.view add foreign key (owner) references permissions.users (username) on update cascade on delete set null; - --- Update Triggers -drop trigger extensions_set_timestamp on ui.extensions; -drop function ui.extensions_set_updated_at(); -create trigger extensions_set_timestamp - before update on ui.extensions - for each row -execute function util_functions.set_updated_at(); - -drop trigger set_timestamp on ui.view; -drop function ui.view_set_updated_at(); -create trigger set_timestamp -before update on ui.view -for each row -execute function util_functions.set_updated_at(); end;