Skip to content

Commit

Permalink
Handle Orphaned Rows Before Adding FKeys
Browse files Browse the repository at this point in the history
Done in case the database has any rows that would violate the foreign key about to be added.
  • Loading branch information
Mythicaeda committed Apr 15, 2024
1 parent 3c18852 commit 3a285c9
Show file tree
Hide file tree
Showing 5 changed files with 258 additions and 95 deletions.
86 changes: 84 additions & 2 deletions deployment/merge_aerie_db/merge_db/migrate_scheduler.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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)
Expand All @@ -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)
Expand All @@ -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)
Expand Down
59 changes: 0 additions & 59 deletions deployment/merge_aerie_db/merge_db/migrate_scheduler_functions.sql
Original file line number Diff line number Diff line change
@@ -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 --
---------------------------------
Expand Down
60 changes: 60 additions & 0 deletions deployment/merge_aerie_db/merge_db/migrate_scheduler_triggers.sql
Original file line number Diff line number Diff line change
@@ -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;
Loading

0 comments on commit 3a285c9

Please sign in to comment.