diff --git a/db-tests/src/test/java/gov/nasa/jpl/aerie/database/PermissionsTest.java b/db-tests/src/test/java/gov/nasa/jpl/aerie/database/PermissionsTest.java index f3d26caf6b..b30749cd28 100644 --- a/db-tests/src/test/java/gov/nasa/jpl/aerie/database/PermissionsTest.java +++ b/db-tests/src/test/java/gov/nasa/jpl/aerie/database/PermissionsTest.java @@ -23,11 +23,28 @@ public class PermissionsTest { private static final File initSqlScriptFile = new File("../merlin-server/sql/merlin/init.sql"); private enum FunctionPermissionKey { - apply_preset, branch_plan, create_merge_rq, withdraw_merge_rq, begin_merge, cancel_merge, - commit_merge, deny_merge, get_conflicting_activities, get_non_conflicting_activities, set_resolution, - set_resolution_bulk, delete_activity_subtree, delete_activity_subtree_bulk, delete_activity_reanchor_plan, - delete_activity_reanchor_plan_bulk, delete_activity_reanchor, delete_activity_reanchor_bulk, get_plan_history, - restore_activity_changelog + apply_preset, + begin_merge, + branch_plan, + cancel_merge, + create_merge_rq, + create_snapshot, + commit_merge, + delete_activity_reanchor, + delete_activity_reanchor_bulk, + delete_activity_reanchor_plan, + delete_activity_reanchor_plan_bulk, + delete_activity_subtree, + delete_activity_subtree_bulk, + deny_merge, + get_conflicting_activities, + get_non_conflicting_activities, + get_plan_history, + restore_activity_changelog, + restore_snapshot, + set_resolution, + set_resolution_bulk, + withdraw_merge_rq } private enum GeneralPermission { OWNER, MISSION_MODEL_OWNER, PLAN_OWNER, PLAN_COLLABORATOR, PLAN_OWNER_COLLABORATOR @@ -176,25 +193,27 @@ void aerieAdminAlwaysReturnsNoCheck(FunctionPermissionKey function) throws SQLEx @Test void getFunctionReturnsAssignedValueUser() throws SQLException { assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("apply_preset", merlinHelper.user.session())); - assertEquals("NO_CHECK", getFunctionPermission("branch_plan", merlinHelper.user.session())); - assertEquals("PLAN_OWNER_SOURCE", getFunctionPermission("create_merge_rq", merlinHelper.user.session())); - assertEquals("PLAN_OWNER_SOURCE", getFunctionPermission("withdraw_merge_rq", merlinHelper.user.session())); assertEquals("PLAN_OWNER_TARGET", getFunctionPermission("begin_merge", merlinHelper.user.session())); + assertEquals("NO_CHECK", getFunctionPermission("branch_plan", merlinHelper.user.session())); assertEquals("PLAN_OWNER_TARGET", getFunctionPermission("cancel_merge", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_SOURCE", getFunctionPermission("create_merge_rq", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("create_snapshot", merlinHelper.user.session())); assertEquals("PLAN_OWNER_TARGET", getFunctionPermission("commit_merge", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_reanchor", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_reanchor_bulk", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_reanchor_plan", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_reanchor_plan_bulk", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_subtree", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_subtree_bulk", merlinHelper.user.session())); assertEquals("PLAN_OWNER_TARGET", getFunctionPermission("deny_merge", merlinHelper.user.session())); assertEquals("NO_CHECK", getFunctionPermission("get_conflicting_activities", merlinHelper.user.session())); assertEquals("NO_CHECK", getFunctionPermission("get_non_conflicting_activities", merlinHelper.user.session())); - assertEquals("PLAN_OWNER_TARGET", getFunctionPermission("set_resolution", merlinHelper.user.session())); - assertEquals("PLAN_OWNER_TARGET", getFunctionPermission("set_resolution_bulk", merlinHelper.user.session())); - assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_subtree", merlinHelper.user.session())); - assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_subtree_bulk", merlinHelper.user.session())); - assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_reanchor_plan", merlinHelper.user.session())); - assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_reanchor_plan_bulk", merlinHelper.user.session())); - assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_reanchor", merlinHelper.user.session())); - assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("delete_activity_reanchor_bulk", merlinHelper.user.session())); assertEquals("NO_CHECK", getFunctionPermission("get_plan_history", merlinHelper.user.session())); assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("restore_activity_changelog", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_COLLABORATOR", getFunctionPermission("restore_snapshot", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_TARGET", getFunctionPermission("set_resolution", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_TARGET", getFunctionPermission("set_resolution_bulk", merlinHelper.user.session())); + assertEquals("PLAN_OWNER_SOURCE", getFunctionPermission("withdraw_merge_rq", merlinHelper.user.session())); } @ParameterizedTest @@ -425,7 +444,7 @@ void testOwner() throws SQLException { // MISSION_MODEL_OWNER: The user must be Owner of the model @Test - void testMissionModel() throws SQLException { + void testMissionModelOwner() throws SQLException { // Setup final int missionModelId = merlinHelper.insertMissionModel(fileId, merlinHelper.user.name()); final int basePlan = merlinHelper.insertPlan(missionModelId, merlinHelper.viewer.name()); diff --git a/db-tests/src/test/java/gov/nasa/jpl/aerie/database/PlanCollaborationTests.java b/db-tests/src/test/java/gov/nasa/jpl/aerie/database/PlanCollaborationTests.java index cfbb568e9a..b69c10cb30 100644 --- a/db-tests/src/test/java/gov/nasa/jpl/aerie/database/PlanCollaborationTests.java +++ b/db-tests/src/test/java/gov/nasa/jpl/aerie/database/PlanCollaborationTests.java @@ -149,6 +149,15 @@ int createSnapshot(final int planId) throws SQLException { } } + void restoreFromSnapshot(final int planId, final int snapshotId) throws SQLException { + try (final var statement = connection.createStatement()) { + statement.execute( + """ + call restore_from_snapshot(%d, %d) + """.formatted(planId, snapshotId)); + } + } + int getParentPlanId(final int planId) throws SQLException{ try (final var statement = connection.createStatement()) { final var res = statement.executeQuery(""" @@ -452,6 +461,7 @@ private void setMergeRequestStatus(final int requestId, final String newStatus) public static void assertActivityEquals(final Activity expected, final Activity actual) { // validate all shared properties + assertEquals(expected.activityId, actual.activityId); assertEquals(expected.name, actual.name); assertEquals(expected.sourceSchedulingGoalId, actual.sourceSchedulingGoalId); assertEquals(expected.createdAt, actual.createdAt); @@ -631,6 +641,126 @@ void snapshotFailsForNonexistentPlanId() throws SQLException{ } } + @Nested + class RestorePlanSnapshotTests{ + @Test + void restoreFailsForNonexistentPlan() throws SQLException { + final int snapshotId = createSnapshot(merlinHelper.insertPlan(missionModelId)); + try { + restoreFromSnapshot(-1, snapshotId); + } catch (SQLException ex) { + if (!ex.getMessage().contains("Cannot Restore: Plan with ID -1 does not exist.")) { + throw ex; + } + } + } + + @Test + void restoreFailsForNonexistentSnapshot() throws SQLException { + final int planId = merlinHelper.insertPlan(missionModelId); + try { + restoreFromSnapshot(planId, -1); + } catch (SQLException ex) { + if (!ex.getMessage().contains("Cannot Restore: Snapshot with ID -1 does not exist.")) { + throw ex; + } + } + } + + @Test + void cannotRestoreSnapshotOfDifferentPlan() throws SQLException { + final int wrongPlan = merlinHelper.insertPlan(missionModelId); + final int snapshotId = createSnapshot(wrongPlan); + final int planId = merlinHelper.insertPlan(missionModelId, merlinHelper.user.name(), "Other Plan"); + + try { + restoreFromSnapshot(planId, snapshotId); + } catch (SQLException ex) { + if (!ex.getMessage().contains("Cannot Restore: Snapshot %d is not a snapshot of Plan 'Other Plan' (ID %d)" + .formatted(snapshotId, planId))) { + throw ex; + } + } + } + + @Test + void cannotRestoreBranchToParentSnapshot() throws SQLException { + final int wrongPlan = merlinHelper.insertPlan(missionModelId); + final int snapshotId = createSnapshot(wrongPlan); + final int branchId = duplicatePlan(wrongPlan, "Different Plan"); + + try{ + restoreFromSnapshot(branchId, snapshotId); + } catch (SQLException ex) { + if (!ex.getMessage().contains("Cannot Restore: Snapshot %d is not a snapshot of Plan 'Different Plan' (ID %d)" + .formatted(snapshotId, branchId))) { + throw ex; + } + } + } + + @Test + void restoresDeletedActivities() throws SQLException { + final int planId = merlinHelper.insertPlan(missionModelId); + final Activity deletedDirective = getActivity(planId, merlinHelper.insertActivity(planId)); + final int snapshotId = createSnapshot(planId); + + // Empty Plan + deleteActivityDirective(planId, deletedDirective.activityId); + assertEquals(0, getActivities(planId).size()); + + // Restore Plan from Snapshot + restoreFromSnapshot(planId, snapshotId); + final var planActivities = getActivities(planId); + assertEquals(1, planActivities.size()); + + // Assert that restored directive equals what it did before (aside from last_updated fields) + final Activity restoredDirective = planActivities.get(0); + assertActivityEquals(deletedDirective, restoredDirective); + } + + @Test + void restoreDeletesAddedActivities() throws SQLException { + final int planId = merlinHelper.insertPlan(missionModelId); + final Activity stableDirective = getActivity(planId, merlinHelper.insertActivity(planId)); + final int snapshotId = createSnapshot(planId); + + // Add new Directive + merlinHelper.insertActivity(planId); + assertEquals(2, getActivities(planId).size()); + + // Restore Plan from Snapshot + restoreFromSnapshot(planId, snapshotId); + final var planActivities = getActivities(planId); + assertEquals(1, planActivities.size()); + + // Assert that remaining directive is the one that was there at the time of the snapshot + final Activity restoredDirective = planActivities.get(0); + assertActivityEquals(stableDirective, restoredDirective); + } + + @Test + void restoresChangedActivities() throws SQLException { + final int planId = merlinHelper.insertPlan(missionModelId); + final int oldDirectiveId = merlinHelper.insertActivity(planId); + updateActivityName("old name", oldDirectiveId, planId); + final Activity oldDirective = getActivity(planId, oldDirectiveId); + final int snapshotId = createSnapshot(planId); + + // Modify Directive + updateActivityName("new name", oldDirective.activityId, planId); + + // Restore Plan from Snapshot + restoreFromSnapshot(planId, snapshotId); + final var planActivities = getActivities(planId); + assertEquals(1, planActivities.size()); + + // Assert that directive's state has been restored + final Activity restoredDirective = planActivities.get(0); + assertActivityEquals(oldDirective, restoredDirective); + } + } + @Nested class DuplicatePlanTests{ @Test diff --git a/deployment/hasura/metadata/databases/AerieMerlin/functions/functions.yaml b/deployment/hasura/metadata/databases/AerieMerlin/functions/functions.yaml index fb13427a0b..4e47c7e642 100644 --- a/deployment/hasura/metadata/databases/AerieMerlin/functions/functions.yaml +++ b/deployment/hasura/metadata/databases/AerieMerlin/functions/functions.yaml @@ -1,19 +1,29 @@ - function: - name: duplicate_plan + name: apply_preset_to_activity schema: hasura_functions configuration: custom_root_fields: - function: duplicate_plan + function: apply_preset_to_activity session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: get_plan_history + name: begin_merge schema: hasura_functions configuration: custom_root_fields: - function: get_plan_history + function: begin_merge + session_argument: hasura_session + permissions: + - role: aerie_admin + - role: user +- function: + name: cancel_merge + schema: hasura_functions + configuration: + custom_root_fields: + function: cancel_merge session_argument: hasura_session permissions: - role: aerie_admin @@ -29,11 +39,11 @@ - role: aerie_admin - role: user - function: - name: begin_merge + name: create_snapshot schema: hasura_functions configuration: custom_root_fields: - function: begin_merge + function: create_snapshot session_argument: hasura_session permissions: - role: aerie_admin @@ -49,163 +59,173 @@ - role: aerie_admin - role: user - function: - name: deny_merge + name: delete_activity_by_pk_reanchor_plan_start schema: hasura_functions configuration: custom_root_fields: - function: deny_merge + function: delete_activity_by_pk_reanchor_plan_start session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: withdraw_merge_request + name: delete_activity_by_pk_reanchor_plan_start_bulk schema: hasura_functions configuration: custom_root_fields: - function: withdraw_merge_request + function: delete_activity_by_pk_reanchor_plan_start_bulk session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: cancel_merge + name: delete_activity_by_pk_reanchor_to_anchor schema: hasura_functions configuration: custom_root_fields: - function: cancel_merge + function: delete_activity_by_pk_reanchor_to_anchor session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: get_non_conflicting_activities + name: delete_activity_by_pk_reanchor_to_anchor_bulk schema: hasura_functions configuration: custom_root_fields: - function: get_non_conflicting_activities + function: delete_activity_by_pk_reanchor_to_anchor_bulk session_argument: hasura_session - exposed_as: query permissions: - role: aerie_admin - role: user - - role: viewer - function: - name: get_conflicting_activities + name: delete_activity_by_pk_delete_subtree schema: hasura_functions configuration: custom_root_fields: - function: get_conflicting_activities + function: delete_activity_by_pk_delete_subtree session_argument: hasura_session - exposed_as: query permissions: - role: aerie_admin - role: user - - role: viewer - function: - name: set_resolution + name: delete_activity_by_pk_delete_subtree_bulk schema: hasura_functions configuration: custom_root_fields: - function: set_resolution + function: delete_activity_by_pk_delete_subtree_bulk session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: set_resolution_bulk + name: deny_merge schema: hasura_functions configuration: custom_root_fields: - function: set_resolution_bulk + function: deny_merge session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: delete_activity_by_pk_reanchor_plan_start + name: duplicate_plan schema: hasura_functions configuration: custom_root_fields: - function: delete_activity_by_pk_reanchor_plan_start + function: duplicate_plan session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: delete_activity_by_pk_reanchor_to_anchor + name: get_conflicting_activities schema: hasura_functions configuration: custom_root_fields: - function: delete_activity_by_pk_reanchor_to_anchor + function: get_conflicting_activities session_argument: hasura_session + exposed_as: query permissions: - role: aerie_admin - role: user + - role: viewer - function: - name: delete_activity_by_pk_delete_subtree + name: get_non_conflicting_activities schema: hasura_functions configuration: custom_root_fields: - function: delete_activity_by_pk_delete_subtree + function: get_non_conflicting_activities session_argument: hasura_session + exposed_as: query permissions: - role: aerie_admin - role: user + - role: viewer - function: - name: delete_activity_by_pk_reanchor_plan_start_bulk + name: get_plan_history schema: hasura_functions configuration: custom_root_fields: - function: delete_activity_by_pk_reanchor_plan_start_bulk + function: get_plan_history session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: delete_activity_by_pk_reanchor_to_anchor_bulk + name: get_resources_at_start_offset schema: hasura_functions configuration: - custom_root_fields: - function: delete_activity_by_pk_reanchor_to_anchor_bulk + custom_name: getResourcesAtStartOffset + permissions: + - role: aerie_admin + - role: user + - role: viewer +- function: + name: restore_activity_changelog + schema: hasura_functions + configuration: + custom_name: restoreActivityFromChangelog session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: delete_activity_by_pk_delete_subtree_bulk + name: restore_from_snapshot schema: hasura_functions configuration: custom_root_fields: - function: delete_activity_by_pk_delete_subtree_bulk + function: restore_from_snapshot session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: apply_preset_to_activity + name: set_resolution schema: hasura_functions configuration: custom_root_fields: - function: apply_preset_to_activity + function: set_resolution session_argument: hasura_session permissions: - role: aerie_admin - role: user - function: - name: get_resources_at_start_offset + name: set_resolution_bulk schema: hasura_functions configuration: - custom_name: getResourcesAtStartOffset + custom_root_fields: + function: set_resolution_bulk + session_argument: hasura_session permissions: - role: aerie_admin - role: user - - role: viewer - function: - name: restore_activity_changelog + name: withdraw_merge_request schema: hasura_functions configuration: - custom_name: restoreActivityFromChangelog + custom_root_fields: + function: withdraw_merge_request session_argument: hasura_session permissions: - role: aerie_admin diff --git a/deployment/hasura/metadata/databases/AerieMerlin/tables/hasura_functions/create_snapshot_return_value.yaml b/deployment/hasura/metadata/databases/AerieMerlin/tables/hasura_functions/create_snapshot_return_value.yaml new file mode 100644 index 0000000000..b9b61421ad --- /dev/null +++ b/deployment/hasura/metadata/databases/AerieMerlin/tables/hasura_functions/create_snapshot_return_value.yaml @@ -0,0 +1,12 @@ +table: + name: create_snapshot_return_value + schema: hasura_functions +select_permissions: + - role: aerie_admin + permission: + columns: [snapshot_id] + filter: {} + - role: user + permission: + columns: [snapshot_id] + filter: {} diff --git a/deployment/hasura/metadata/databases/AerieMerlin/tables/metadata/snapshot_activity_tags.yaml b/deployment/hasura/metadata/databases/AerieMerlin/tables/metadata/snapshot_activity_tags.yaml index 1f02c284bb..65621ebf5f 100644 --- a/deployment/hasura/metadata/databases/AerieMerlin/tables/metadata/snapshot_activity_tags.yaml +++ b/deployment/hasura/metadata/databases/AerieMerlin/tables/metadata/snapshot_activity_tags.yaml @@ -10,3 +10,23 @@ object_relationships: - name: tag using: foreign_key_constraint_on: tag_id +select_permissions: + - role: aerie_admin + permission: + columns: [snapshot_id, directive_id, tag_id] + filter: {} + allow_aggregations: true + - role: user + permission: + columns: [snapshot_id, directive_id, tag_id] + filter: {} + allow_aggregations: true + - role: viewer + permission: + columns: [snapshot_id, directive_id, tag_id] + filter: {} + allow_aggregations: true +delete_permissions: + - role: aerie_admin + permission: + filter: {} diff --git a/deployment/hasura/metadata/databases/AerieMerlin/tables/public_plan_snapshot.yaml b/deployment/hasura/metadata/databases/AerieMerlin/tables/public_plan_snapshot.yaml index b67a2bb96f..571be87d29 100644 --- a/deployment/hasura/metadata/databases/AerieMerlin/tables/public_plan_snapshot.yaml +++ b/deployment/hasura/metadata/databases/AerieMerlin/tables/public_plan_snapshot.yaml @@ -14,17 +14,17 @@ object_relationships: select_permissions: - role: aerie_admin permission: - columns: [snapshot_id, plan_id, revision, name, duration, start_time] + columns: [snapshot_id, plan_id, revision, snapshot_name, taken_by, taken_at] filter: {} allow_aggregations: true - role: user permission: - columns: [snapshot_id, plan_id, revision, name, duration, start_time] + columns: [snapshot_id, plan_id, revision, snapshot_name, taken_by, taken_at] filter: {} allow_aggregations: true - role: viewer permission: - columns: [snapshot_id, plan_id, revision, name, duration, start_time] + columns: [snapshot_id, plan_id, revision, snapshot_name, taken_by, taken_at] filter: {} allow_aggregations: true delete_permissions: diff --git a/deployment/hasura/metadata/databases/AerieMerlin/tables/public_plan_snapshot_activities.yaml b/deployment/hasura/metadata/databases/AerieMerlin/tables/public_plan_snapshot_activities.yaml index cdd417cf63..5235b8439b 100644 --- a/deployment/hasura/metadata/databases/AerieMerlin/tables/public_plan_snapshot_activities.yaml +++ b/deployment/hasura/metadata/databases/AerieMerlin/tables/public_plan_snapshot_activities.yaml @@ -16,3 +16,26 @@ array_relationships: column_mapping: id: directive_id snapshot_id: snapshot_id +select_permissions: + - role: aerie_admin + permission: + columns: [snapshot_id, id, name, source_scheduling_goal_id, created_at, last_modified_at, last_modified_by, + start_offset, type, arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start] + filter: {} + allow_aggregations: true + - role: user + permission: + columns: [snapshot_id, id, name, source_scheduling_goal_id, created_at, last_modified_at, last_modified_by, + start_offset, type, arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start] + filter: {} + allow_aggregations: true + - role: viewer + permission: + columns: [snapshot_id, id, name, source_scheduling_goal_id, created_at, last_modified_at, last_modified_by, + start_offset, type, arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start] + filter: {} + allow_aggregations: true +delete_permissions: + - role: aerie_admin + permission: + filter: {} diff --git a/deployment/hasura/metadata/databases/AerieMerlin/tables/tables.yaml b/deployment/hasura/metadata/databases/AerieMerlin/tables/tables.yaml index 549b9d87ec..059bf78aa8 100644 --- a/deployment/hasura/metadata/databases/AerieMerlin/tables/tables.yaml +++ b/deployment/hasura/metadata/databases/AerieMerlin/tables/tables.yaml @@ -20,6 +20,7 @@ - "!include public_plan_collaborators.yaml" - "!include public_plan_dataset.yaml" - "!include public_plan_snapshot.yaml" +- "!include public_plan_snapshot_activities.yaml" - "!include public_preset_to_directive.yaml" - "!include public_profile.yaml" - "!include public_profile_segment.yaml" @@ -38,6 +39,7 @@ - "!include hasura_functions/cancel_merge_return_value.yaml" - "!include hasura_functions/commit_merge_return_value.yaml" - "!include hasura_functions/create_merge_return_value.yaml" +- "!include hasura_functions/create_snapshot_return_value.yaml" - "!include hasura_functions/delete_anchor_return_value.yaml" - "!include hasura_functions/deny_merge_return_value.yaml" - "!include hasura_functions/duplicate_plan_return_value.yaml" @@ -51,6 +53,7 @@ - "!include metadata/activity_directive_tags.yaml" - "!include metadata/constraint_tags.yaml" - "!include metadata/plan_tags.yaml" +- "!include metadata/snapshot_activity_tags.yaml" - "!include metadata/users_allowed_roles.yaml" - "!include metadata/user_roles.yaml" - "!include metadata/user_role_permission.yaml" diff --git a/deployment/hasura/migrations/AerieMerlin/24_user_plan_snapshots/down.sql b/deployment/hasura/migrations/AerieMerlin/24_user_plan_snapshots/down.sql new file mode 100644 index 0000000000..381ea4576b --- /dev/null +++ b/deployment/hasura/migrations/AerieMerlin/24_user_plan_snapshots/down.sql @@ -0,0 +1,378 @@ +-- Hasura function +drop function hasura_functions.restore_from_snapshot(_plan_id integer, _snapshot_id integer, hasura_session json); +drop function hasura_functions.create_snapshot(_plan_id integer, _snapshot_name text, hasura_session json); +drop table hasura_functions.create_snapshot_return_value; + +-- Remove 'create_snapshot' key from all roles it is on +update metadata.user_role_permission + set function_permissions = (function_permissions - 'create_snapshot') - 'restore_snapshot'; + +-- Undo alphabetize metadata.action_permission_key +drop type metadata.action_permission_key; +create type metadata.action_permission_key + as enum ('simulate', 'schedule', 'insert_ext_dataset', 'check_constraints', 'create_expansion_set', + 'create_expansion_rule', 'expand_all_activities', 'sequence_seq_json_bulk', 'resource_samples'); + +-- Update function permissions key enum +drop procedure metadata.check_merge_permissions(_function metadata.function_permission_key, _permission metadata.permission, _plan_id_receiving integer, _plan_id_supplying integer, _user text); +drop procedure metadata.check_merge_permissions(_function metadata.function_permission_key, _merge_request_id integer, hasura_session json); +drop function metadata.raise_if_plan_merge_permission(_function metadata.function_permission_key, _permission metadata.permission); +drop procedure metadata.check_general_permissions(_function metadata.function_permission_key, _permission metadata.permission, _plan_id integer, _user text); +drop function metadata.get_function_permissions(_function metadata.function_permission_key, hasura_session json); + +drop type metadata.function_permission_key; +create type metadata.function_permission_key + as enum ('apply_preset', 'branch_plan', 'create_merge_rq', 'withdraw_merge_rq', 'begin_merge', 'cancel_merge', + 'commit_merge', 'deny_merge', 'get_conflicting_activities', 'get_non_conflicting_activities', 'set_resolution', + 'set_resolution_bulk', 'delete_activity_subtree', 'delete_activity_subtree_bulk', 'delete_activity_reanchor_plan', + 'delete_activity_reanchor_plan_bulk', 'delete_activity_reanchor', 'delete_activity_reanchor_bulk', 'get_plan_history', + 'restore_activity_changelog'); + +create function metadata.get_function_permissions(_function metadata.function_permission_key, hasura_session json) + returns metadata.permission + stable + language plpgsql as $$ + declare + _role text; + _function_permission metadata.permission; + begin + _role := metadata.get_role(hasura_session); + -- The aerie_admin role is always treated as having NO_CHECK permissions on all functions. + if _role = 'aerie_admin' then return 'NO_CHECK'; end if; + + select (function_permissions ->> _function::text)::metadata.permission + from metadata.user_role_permission urp + where urp.role = _role + into _function_permission; + + -- The absence of the function key means that the role does not have permission to perform the function. + if _function_permission is null then + raise insufficient_privilege + using message = 'User with role '''|| _role ||''' is not permitted to run '''|| _function ||''''; + end if; + + return _function_permission::metadata.permission; + end + $$; +create procedure metadata.check_general_permissions(_function metadata.function_permission_key, _permission metadata.permission, _plan_id integer, _user text) +language plpgsql as $$ +declare + _mission_model_id integer; + _plan_name text; +begin + select name from public.plan where id = _plan_id into _plan_name; + + -- MISSION_MODEL_OWNER: The user must own the relevant Mission Model + if _permission = 'MISSION_MODEL_OWNER' then + select id from public.mission_model mm + where mm.id = (select model_id from plan p where p.id = _plan_id) + into _mission_model_id; + + if not exists(select * from public.mission_model mm where mm.id = _mission_model_id and mm.owner =_user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not MISSION_MODEL_OWNER on Model ' || _mission_model_id ||'.'; + end if; + + -- OWNER: The user must be the owner of all relevant objects directly used by the KEY + -- In most cases, OWNER is equivalent to PLAN_OWNER. Use a custom solution when that is not true. + elseif _permission = 'OWNER' then + if not exists(select * from public.plan p where p.id = _plan_id and p.owner = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not OWNER on Plan ' || _plan_id ||' ('|| _plan_name ||').'; + end if; + + -- PLAN_OWNER: The user must be the Owner of the relevant Plan + elseif _permission = 'PLAN_OWNER' then + if not exists(select * from public.plan p where p.id = _plan_id and p.owner = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER on Plan '|| _plan_id ||' ('|| _plan_name ||').'; + end if; + + -- PLAN_COLLABORATOR: The user must be a Collaborator of the relevant Plan. The Plan Owner is NOT considered a Collaborator of the Plan + elseif _permission = 'PLAN_COLLABORATOR' then + if not exists(select * from public.plan_collaborators pc where pc.plan_id = _plan_id and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_COLLABORATOR on Plan '|| _plan_id ||' ('|| _plan_name ||').'; + end if; + + -- PLAN_OWNER_COLLABORATOR: The user must be either the Owner or a Collaborator of the relevant Plan + elseif _permission = 'PLAN_OWNER_COLLABORATOR' then + if not exists(select * from public.plan p where p.id = _plan_id and p.owner = _user) then + if not exists(select * from public.plan_collaborators pc where pc.plan_id = _plan_id and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER_COLLABORATOR on Plan '|| _plan_id ||' ('|| _plan_name ||').'; + end if; + end if; + end if; +end +$$; +create function metadata.raise_if_plan_merge_permission(_function metadata.function_permission_key, _permission metadata.permission) +returns void +immutable +language plpgsql as $$ +begin + if _permission::text = any(array['PLAN_OWNER_SOURCE', 'PLAN_COLLABORATOR_SOURCE', 'PLAN_OWNER_COLLABORATOR_SOURCE', + 'PLAN_OWNER_TARGET', 'PLAN_COLLABORATOR_TARGET', 'PLAN_OWNER_COLLABORATOR_TARGET']) + then + raise 'Invalid Permission: The Permission ''%'' may not be applied to function ''%''', _permission, _function; + end if; +end +$$; +create procedure metadata.check_merge_permissions(_function metadata.function_permission_key, _merge_request_id integer, hasura_session json) +language plpgsql as $$ +declare + _plan_id_receiving_changes integer; + _plan_id_supplying_changes integer; + _function_permission metadata.permission; + _user text; +begin + select plan_id_receiving_changes + from merge_request mr + where mr.id = _merge_request_id + into _plan_id_receiving_changes; + + select plan_id + from public.plan_snapshot ps, merge_request mr + where mr.id = _merge_request_id and ps.snapshot_id = mr.snapshot_id_supplying_changes + into _plan_id_supplying_changes; + + _user := (hasura_session ->> 'x-hasura-user-id'); + _function_permission := metadata.get_function_permissions('get_non_conflicting_activities', hasura_session); + call metadata.check_merge_permissions(_function, _function_permission, _plan_id_receiving_changes, + _plan_id_supplying_changes, _user); +end +$$; +create procedure metadata.check_merge_permissions(_function metadata.function_permission_key, _permission metadata.permission, _plan_id_receiving integer, _plan_id_supplying integer, _user text) +language plpgsql as $$ +declare + _supplying_plan_name text; + _receiving_plan_name text; +begin + select name from public.plan where id = _plan_id_supplying into _supplying_plan_name; + select name from public.plan where id = _plan_id_receiving into _receiving_plan_name; + + -- MISSION_MODEL_OWNER: The user must own the relevant Mission Model + if _permission = 'MISSION_MODEL_OWNER' then + call metadata.check_general_permissions(_function, _permission, _plan_id_receiving, _user); + + -- OWNER: The user must be the Owner of both Plans + elseif _permission = 'OWNER' then + if not (exists(select * from public.plan p where p.id = _plan_id_receiving and p.owner = _user)) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': ''' + || _user ||''' is not OWNER on Plan '|| _plan_id_receiving + ||' ('|| _receiving_plan_name ||').'; + elseif not (exists(select * from public.plan p2 where p2.id = _plan_id_supplying and p2.owner = _user)) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': ''' + || _user ||''' is not OWNER on Plan '|| _plan_id_supplying + ||' ('|| _supplying_plan_name ||').'; + end if; + + -- PLAN_OWNER: The user must be the Owner of either Plan + elseif _permission = 'PLAN_OWNER' then + if not exists(select * + from public.plan p + where (p.id = _plan_id_receiving or p.id = _plan_id_supplying) + and p.owner = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': ''' + || _user ||''' is not PLAN_OWNER on either Plan '|| _plan_id_receiving + ||' ('|| _receiving_plan_name ||') or Plan '|| _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + end if; + + -- PLAN_COLLABORATOR: The user must be a Collaborator of either Plan. The Plan Owner is NOT considered a Collaborator of the Plan + elseif _permission = 'PLAN_COLLABORATOR' then + if not exists(select * + from public.plan_collaborators pc + where (pc.plan_id = _plan_id_receiving or pc.plan_id = _plan_id_supplying) + and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': ''' + || _user ||''' is not PLAN_COLLABORATOR on either Plan '|| _plan_id_receiving + ||' ('|| _receiving_plan_name ||') or Plan '|| _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + end if; + + -- PLAN_OWNER_COLLABORATOR: The user must be either the Owner or a Collaborator of either Plan + elseif _permission = 'PLAN_OWNER_COLLABORATOR' then + if not exists(select * + from public.plan p + where (p.id = _plan_id_receiving or p.id = _plan_id_supplying) + and p.owner = _user) then + if not exists(select * + from public.plan_collaborators pc + where (pc.plan_id = _plan_id_receiving or pc.plan_id = _plan_id_supplying) + and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': ''' + || _user ||''' is not PLAN_OWNER_COLLABORATOR on either Plan '|| _plan_id_receiving + ||' ('|| _receiving_plan_name ||') or Plan '|| _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + + end if; + end if; + + -- PLAN_OWNER_SOURCE: The user must be the Owner of the Supplying Plan + elseif _permission = 'PLAN_OWNER_SOURCE' then + if not exists(select * + from public.plan p + where p.id = _plan_id_supplying and p.owner = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER on Source Plan ' + || _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + end if; + + -- PLAN_COLLABORATOR_SOURCE: The user must be a Collaborator of the Supplying Plan. + elseif _permission = 'PLAN_COLLABORATOR_SOURCE' then + if not exists(select * + from public.plan_collaborators pc + where pc.plan_id = _plan_id_supplying and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_COLLABORATOR on Source Plan ' + || _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + end if; + + -- PLAN_OWNER_COLLABORATOR_SOURCE: The user must be either the Owner or a Collaborator of the Supplying Plan. + elseif _permission = 'PLAN_OWNER_COLLABORATOR_SOURCE' then + if not exists(select * + from public.plan p + where p.id = _plan_id_supplying and p.owner = _user) then + if not exists(select * + from public.plan_collaborators pc + where pc.plan_id = _plan_id_supplying and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER_COLLABORATOR on Source Plan ' + || _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + end if; + end if; + + -- PLAN_OWNER_TARGET: The user must be the Owner of the Receiving Plan. + elseif _permission = 'PLAN_OWNER_TARGET' then + if not exists(select * + from public.plan p + where p.id = _plan_id_receiving and p.owner = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER on Target Plan ' + || _plan_id_receiving ||' ('|| _receiving_plan_name ||').'; + end if; + + -- PLAN_COLLABORATOR_TARGET: The user must be a Collaborator of the Receiving Plan. + elseif _permission = 'PLAN_COLLABORATOR_TARGET' then + if not exists(select * + from public.plan_collaborators pc + where pc.plan_id = _plan_id_receiving and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_COLLABORATOR on Target Plan ' + || _plan_id_receiving ||' ('|| _receiving_plan_name ||').'; + end if; + + -- PLAN_OWNER_COLLABORATOR_TARGET: The user must be either the Owner or a Collaborator of the Receiving Plan. + elseif _permission = 'PLAN_OWNER_COLLABORATOR_TARGET' then + if not exists(select * + from public.plan p + where p.id = _plan_id_receiving and p.owner = _user) then + if not exists(select * + from public.plan_collaborators pc + where pc.plan_id = _plan_id_receiving and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER_COLLABORATOR on Target Plan ' + || _plan_id_receiving ||' ('|| _receiving_plan_name ||').'; + end if; + end if; + end if; +end +$$; + +-- Remove restore_from_snapshot +comment on procedure restore_from_snapshot(_plan_id integer, _snapshot_id integer) is null; +drop procedure restore_from_snapshot(_plan_id integer, _snapshot_id integer); + +-- Remove override for create_snapshot +comment on function create_snapshot(integer, text, text) is null; +comment on function create_snapshot(integer) is e'' + 'Create a snapshot of the specified plan. A snapshot consists of:' + ' - The plan''s name, revision, duration, start time, and id' + ' - All the activities in the plan' + ' - The preset status of those activities' + ' - The tags on those activities'; + +drop function create_snapshot(_plan_id integer, _user text, _snapshot_name text); +create or replace function create_snapshot(_plan_id integer) + returns integer -- snapshot id inserted into the table + language plpgsql as $$ + declare + validate_plan_id integer; + inserted_snapshot_id integer; +begin + select id from plan where plan.id = _plan_id into validate_plan_id; + if validate_plan_id is null then + raise exception 'Plan % does not exist.', _plan_id; + end if; + + insert into plan_snapshot(plan_id, revision, name, duration, start_time) + select id, revision, name, duration, start_time + from plan where id = _plan_id + returning snapshot_id into inserted_snapshot_id; + insert into plan_snapshot_activities( + snapshot_id, id, name, source_scheduling_goal_id, created_at, + last_modified_at, last_modified_by, start_offset, type, + arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start) + select + inserted_snapshot_id, -- this is the snapshot id + id, name, source_scheduling_goal_id, created_at, -- these are the rest of the data for an activity row + last_modified_at, last_modified_by, start_offset, type, arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start + from activity_directive where activity_directive.plan_id = _plan_id; + insert into preset_to_snapshot_directive(preset_id, activity_id, snapshot_id) + select ptd.preset_id, ptd.activity_id, inserted_snapshot_id + from preset_to_directive ptd + where ptd.plan_id = _plan_id; + insert into metadata.snapshot_activity_tags(snapshot_id, directive_id, tag_id) + select inserted_snapshot_id, directive_id, tag_id + from metadata.activity_directive_tags adt + where adt.plan_id = _plan_id; + + --all snapshots in plan_latest_snapshot for plan plan_id become the parent of the current snapshot + insert into plan_snapshot_parent(snapshot_id, parent_snapshot_id) + select inserted_snapshot_id, snapshot_id + from plan_latest_snapshot where plan_latest_snapshot.plan_id = _plan_id; + + --remove all of those entries from plan_latest_snapshot and add this new snapshot. + delete from plan_latest_snapshot where plan_latest_snapshot.plan_id = _plan_id; + insert into plan_latest_snapshot(plan_id, snapshot_id) values (_plan_id, inserted_snapshot_id); + + return inserted_snapshot_id; + end; +$$; + + +-- Update plan_snapshot +comment on table plan_snapshot is e'' + 'A record of the metadata associated with a plan, excluding tags.'; +comment on column plan_snapshot.snapshot_id is null; +comment on column plan_snapshot.plan_id is null; +comment on column plan_snapshot.revision is null; +comment on column plan_snapshot.snapshot_name is null; +comment on column plan_snapshot.taken_by is null; +comment on column plan_snapshot.taken_at is null; + +alter table plan_snapshot + drop constraint snapshot_name_unique_per_plan, + drop column taken_at, + drop column taken_by, + drop column snapshot_name, + add column name text, + add column duration interval, + add column start_time timestamptz; + +update plan_snapshot ps +set start_time = p.start_time, + name = p.name, + duration = p.duration +from plan p +where ps.plan_id = p.id; + +alter table plan_snapshot + alter column name set not null, + alter column duration set not null , + alter column start_time set not null; + +call migrations.mark_migration_rolled_back('24'); diff --git a/deployment/hasura/migrations/AerieMerlin/24_user_plan_snapshots/up.sql b/deployment/hasura/migrations/AerieMerlin/24_user_plan_snapshots/up.sql new file mode 100644 index 0000000000..678fb1e3bd --- /dev/null +++ b/deployment/hasura/migrations/AerieMerlin/24_user_plan_snapshots/up.sql @@ -0,0 +1,562 @@ +-- Update plan_snapshot +alter table plan_snapshot + drop column name, + drop column duration, + drop column start_time, + add column snapshot_name text, + add column taken_by text, + add column taken_at timestamptz not null default now(), + add constraint snapshot_name_unique_per_plan + unique (plan_id, snapshot_name); + + +comment on table plan_snapshot is e'' + 'A record of the state of a plan at a given time.'; +comment on column plan_snapshot.snapshot_id is e'' + 'The identifier of the snapshot.'; +comment on column plan_snapshot.plan_id is e'' + 'The plan that this is a snapshot of.'; +comment on column plan_snapshot.revision is e'' + 'The revision of the plan at the time the snapshot was taken.'; +comment on column plan_snapshot.snapshot_name is e'' + 'A human-readable name for the snapshot.'; +comment on column plan_snapshot.taken_by is e'' + 'The user who took the snapshot.'; +comment on column plan_snapshot.taken_at is e'' + 'The time that the snapshot was taken.'; + +-- Create override for create_snapshot +create or replace function create_snapshot(_plan_id integer) + returns integer + language plpgsql as $$ +begin + return create_snapshot(_plan_id, null, null); +end +$$; + +create function create_snapshot(_plan_id integer, _user text, _snapshot_name text) + returns integer -- snapshot id inserted into the table + language plpgsql as $$ + declare + validate_plan_id integer; + inserted_snapshot_id integer; +begin + select id from plan where plan.id = _plan_id into validate_plan_id; + if validate_plan_id is null then + raise exception 'Plan % does not exist.', _plan_id; + end if; + + insert into plan_snapshot(plan_id, revision, snapshot_name, taken_by) + select id, revision, _snapshot_name, _user + from plan where id = _plan_id + returning snapshot_id into inserted_snapshot_id; + insert into plan_snapshot_activities( + snapshot_id, id, name, source_scheduling_goal_id, created_at, + last_modified_at, last_modified_by, start_offset, type, + arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start) + select + inserted_snapshot_id, -- this is the snapshot id + id, name, source_scheduling_goal_id, created_at, -- these are the rest of the data for an activity row + last_modified_at, last_modified_by, start_offset, type, + arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start + from activity_directive where activity_directive.plan_id = _plan_id; + insert into preset_to_snapshot_directive(preset_id, activity_id, snapshot_id) + select ptd.preset_id, ptd.activity_id, inserted_snapshot_id + from preset_to_directive ptd + where ptd.plan_id = _plan_id; + insert into metadata.snapshot_activity_tags(snapshot_id, directive_id, tag_id) + select inserted_snapshot_id, directive_id, tag_id + from metadata.activity_directive_tags adt + where adt.plan_id = _plan_id; + + --all snapshots in plan_latest_snapshot for plan plan_id become the parent of the current snapshot + insert into plan_snapshot_parent(snapshot_id, parent_snapshot_id) + select inserted_snapshot_id, snapshot_id + from plan_latest_snapshot where plan_latest_snapshot.plan_id = _plan_id; + + --remove all of those entries from plan_latest_snapshot and add this new snapshot. + delete from plan_latest_snapshot where plan_latest_snapshot.plan_id = _plan_id; + insert into plan_latest_snapshot(plan_id, snapshot_id) values (_plan_id, inserted_snapshot_id); + + return inserted_snapshot_id; + end; +$$; + +comment on function create_snapshot(integer) is e'' + 'See comment on create_snapshot(integer, text, text)'; + +comment on function create_snapshot(integer, text, text) is e'' + 'Create a snapshot of the specified plan. A snapshot consists of:' + ' - The plan''s id and revision' + ' - All the activities in the plan' + ' - The preset status of those activities' + ' - The tags on those activities' + ' - When the snapshot was taken' + ' - Optionally: who took the snapshot and a name'; + +-- Restore From Snapshot +create procedure restore_from_snapshot(_plan_id integer, _snapshot_id integer) + language plpgsql as $$ + declare + _snapshot_name text; + _plan_name text; + begin + -- Input Validation + select name from plan where id = _plan_id into _plan_name; + if _plan_name is null then + raise exception 'Cannot Restore: Plan with ID % does not exist.', _plan_id; + end if; + if not exists(select snapshot_id from plan_snapshot where snapshot_id = _snapshot_id) then + raise exception 'Cannot Restore: Snapshot with ID % does not exist.', _snapshot_id; + end if; + if not exists(select snapshot_id from plan_snapshot where _snapshot_id = snapshot_id and _plan_id = plan_id ) then + select snapshot_name from plan_snapshot where snapshot_id = _snapshot_id into _snapshot_name; + if _snapshot_name is not null then + raise exception 'Cannot Restore: Snapshot ''%'' (ID %) is not a snapshot of Plan ''%'' (ID %)', + _snapshot_name, _snapshot_id, _plan_name, _plan_id; + else + raise exception 'Cannot Restore: Snapshot % is not a snapshot of Plan ''%'' (ID %)', + _snapshot_id, _plan_name, _plan_id; + end if; + end if; + + -- Catch Plan_Locked + call plan_locked_exception(_plan_id); + + -- Record the Union of Activities in Plan and Snapshot + -- and note which ones have been added since the Snapshot was taken (in_snapshot = false) + create temp table diff( + activity_id integer, + in_snapshot boolean not null + ); + insert into diff(activity_id, in_snapshot) + select id as activity_id, true + from plan_snapshot_activities where snapshot_id = _snapshot_id; + + insert into diff (activity_id, in_snapshot) + select activity_id, false + from( + select id as activity_id + from activity_directive + where plan_id = _plan_id + except + select activity_id + from diff) a; + + -- Remove any added activities + delete from activity_directive ad + using diff d + where (ad.id, ad.plan_id) = (d.activity_id, _plan_id) + and d.in_snapshot is false; + + -- Upsert the rest + insert into activity_directive ( + id, plan_id, name, source_scheduling_goal_id, created_at, last_modified_at, last_modified_by, + start_offset, type, arguments, last_modified_arguments_at, metadata, + anchor_id, anchored_to_start) + select psa.id, _plan_id, psa.name, psa.source_scheduling_goal_id, psa.created_at, psa.last_modified_at, psa.last_modified_by, + psa.start_offset, psa.type, psa.arguments, psa.last_modified_arguments_at, psa.metadata, + psa.anchor_id, psa.anchored_to_start + from plan_snapshot_activities psa + where psa.snapshot_id = _snapshot_id + on conflict (id, plan_id) do update + -- 'last_modified_at' and 'last_modified_arguments_at' are skipped during update, as triggers will overwrite them to now() + set name = excluded.name, + source_scheduling_goal_id = excluded.source_scheduling_goal_id, + created_at = excluded.created_at, + last_modified_by = excluded.last_modified_by, + start_offset = excluded.start_offset, + type = excluded.type, + arguments = excluded.arguments, + metadata = excluded.metadata, + anchor_id = excluded.anchor_id, + anchored_to_start = excluded.anchored_to_start; + + -- Tags + delete from metadata.activity_directive_tags adt + using diff d + where (adt.directive_id, adt.plan_id) = (d.activity_id, _plan_id); + + insert into metadata.activity_directive_tags(directive_id, plan_id, tag_id) + select sat.directive_id, _plan_id, sat.tag_id + from metadata.snapshot_activity_tags sat + where sat.snapshot_id = _snapshot_id + on conflict (directive_id, plan_id, tag_id) do nothing; + + -- Presets + delete from preset_to_directive + where plan_id = _plan_id; + insert into preset_to_directive(preset_id, activity_id, plan_id) + select pts.preset_id, pts.activity_id, _plan_id + from preset_to_snapshot_directive pts + where pts.snapshot_id = _snapshot_id + on conflict (activity_id, plan_id) + do update set preset_id = excluded.preset_id; + + -- Clean up + drop table diff; + end +$$; + +comment on procedure restore_from_snapshot(_plan_id integer, _snapshot_id integer) is e'' + 'Restore a plan to its state described in the given snapshot.'; + +-- Update function permissions key enum +-- Normally, adding to the type can be done via a command like +-- alter type metadata.function_permission_key add value 'create_snapshot' after 'create_merge_rq'; +-- However, since this migration needs to fix the order of the enum, it is also being dropped and recreated in the up +drop procedure metadata.check_merge_permissions(_function metadata.function_permission_key, _permission metadata.permission, _plan_id_receiving integer, _plan_id_supplying integer, _user text); +drop procedure metadata.check_merge_permissions(_function metadata.function_permission_key, _merge_request_id integer, hasura_session json); +drop function metadata.raise_if_plan_merge_permission(_function metadata.function_permission_key, _permission metadata.permission); +drop procedure metadata.check_general_permissions(_function metadata.function_permission_key, _permission metadata.permission, _plan_id integer, _user text); +drop function metadata.get_function_permissions(_function metadata.function_permission_key, hasura_session json); + +drop type metadata.function_permission_key; +create type metadata.function_permission_key + as enum ( + 'apply_preset', + 'begin_merge', + 'branch_plan', + 'cancel_merge', + 'commit_merge', + 'create_merge_rq', + 'create_snapshot', + 'delete_activity_reanchor', + 'delete_activity_reanchor_bulk', + 'delete_activity_reanchor_plan', + 'delete_activity_reanchor_plan_bulk', + 'delete_activity_subtree', + 'delete_activity_subtree_bulk', + 'deny_merge', + 'get_conflicting_activities', + 'get_non_conflicting_activities', + 'get_plan_history', + 'restore_activity_changelog', + 'restore_snapshot', + 'set_resolution', + 'set_resolution_bulk', + 'withdraw_merge_rq' + ); + +create function metadata.get_function_permissions(_function metadata.function_permission_key, hasura_session json) + returns metadata.permission + stable + language plpgsql as $$ + declare + _role text; + _function_permission metadata.permission; + begin + _role := metadata.get_role(hasura_session); + -- The aerie_admin role is always treated as having NO_CHECK permissions on all functions. + if _role = 'aerie_admin' then return 'NO_CHECK'; end if; + + select (function_permissions ->> _function::text)::metadata.permission + from metadata.user_role_permission urp + where urp.role = _role + into _function_permission; + + -- The absence of the function key means that the role does not have permission to perform the function. + if _function_permission is null then + raise insufficient_privilege + using message = 'User with role '''|| _role ||''' is not permitted to run '''|| _function ||''''; + end if; + + return _function_permission::metadata.permission; + end + $$; +create procedure metadata.check_general_permissions(_function metadata.function_permission_key, _permission metadata.permission, _plan_id integer, _user text) +language plpgsql as $$ +declare + _mission_model_id integer; + _plan_name text; +begin + select name from public.plan where id = _plan_id into _plan_name; + + -- MISSION_MODEL_OWNER: The user must own the relevant Mission Model + if _permission = 'MISSION_MODEL_OWNER' then + select id from public.mission_model mm + where mm.id = (select model_id from plan p where p.id = _plan_id) + into _mission_model_id; + + if not exists(select * from public.mission_model mm where mm.id = _mission_model_id and mm.owner =_user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not MISSION_MODEL_OWNER on Model ' || _mission_model_id ||'.'; + end if; + + -- OWNER: The user must be the owner of all relevant objects directly used by the KEY + -- In most cases, OWNER is equivalent to PLAN_OWNER. Use a custom solution when that is not true. + elseif _permission = 'OWNER' then + if not exists(select * from public.plan p where p.id = _plan_id and p.owner = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not OWNER on Plan ' || _plan_id ||' ('|| _plan_name ||').'; + end if; + + -- PLAN_OWNER: The user must be the Owner of the relevant Plan + elseif _permission = 'PLAN_OWNER' then + if not exists(select * from public.plan p where p.id = _plan_id and p.owner = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER on Plan '|| _plan_id ||' ('|| _plan_name ||').'; + end if; + + -- PLAN_COLLABORATOR: The user must be a Collaborator of the relevant Plan. The Plan Owner is NOT considered a Collaborator of the Plan + elseif _permission = 'PLAN_COLLABORATOR' then + if not exists(select * from public.plan_collaborators pc where pc.plan_id = _plan_id and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_COLLABORATOR on Plan '|| _plan_id ||' ('|| _plan_name ||').'; + end if; + + -- PLAN_OWNER_COLLABORATOR: The user must be either the Owner or a Collaborator of the relevant Plan + elseif _permission = 'PLAN_OWNER_COLLABORATOR' then + if not exists(select * from public.plan p where p.id = _plan_id and p.owner = _user) then + if not exists(select * from public.plan_collaborators pc where pc.plan_id = _plan_id and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER_COLLABORATOR on Plan '|| _plan_id ||' ('|| _plan_name ||').'; + end if; + end if; + end if; +end +$$; +create function metadata.raise_if_plan_merge_permission(_function metadata.function_permission_key, _permission metadata.permission) +returns void +immutable +language plpgsql as $$ +begin + if _permission::text = any(array['PLAN_OWNER_SOURCE', 'PLAN_COLLABORATOR_SOURCE', 'PLAN_OWNER_COLLABORATOR_SOURCE', + 'PLAN_OWNER_TARGET', 'PLAN_COLLABORATOR_TARGET', 'PLAN_OWNER_COLLABORATOR_TARGET']) + then + raise 'Invalid Permission: The Permission ''%'' may not be applied to function ''%''', _permission, _function; + end if; +end +$$; +create procedure metadata.check_merge_permissions(_function metadata.function_permission_key, _merge_request_id integer, hasura_session json) +language plpgsql as $$ +declare + _plan_id_receiving_changes integer; + _plan_id_supplying_changes integer; + _function_permission metadata.permission; + _user text; +begin + select plan_id_receiving_changes + from merge_request mr + where mr.id = _merge_request_id + into _plan_id_receiving_changes; + + select plan_id + from public.plan_snapshot ps, merge_request mr + where mr.id = _merge_request_id and ps.snapshot_id = mr.snapshot_id_supplying_changes + into _plan_id_supplying_changes; + + _user := (hasura_session ->> 'x-hasura-user-id'); + _function_permission := metadata.get_function_permissions('get_non_conflicting_activities', hasura_session); + call metadata.check_merge_permissions(_function, _function_permission, _plan_id_receiving_changes, + _plan_id_supplying_changes, _user); +end +$$; +create procedure metadata.check_merge_permissions(_function metadata.function_permission_key, _permission metadata.permission, _plan_id_receiving integer, _plan_id_supplying integer, _user text) +language plpgsql as $$ +declare + _supplying_plan_name text; + _receiving_plan_name text; +begin + select name from public.plan where id = _plan_id_supplying into _supplying_plan_name; + select name from public.plan where id = _plan_id_receiving into _receiving_plan_name; + + -- MISSION_MODEL_OWNER: The user must own the relevant Mission Model + if _permission = 'MISSION_MODEL_OWNER' then + call metadata.check_general_permissions(_function, _permission, _plan_id_receiving, _user); + + -- OWNER: The user must be the Owner of both Plans + elseif _permission = 'OWNER' then + if not (exists(select * from public.plan p where p.id = _plan_id_receiving and p.owner = _user)) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': ''' + || _user ||''' is not OWNER on Plan '|| _plan_id_receiving + ||' ('|| _receiving_plan_name ||').'; + elseif not (exists(select * from public.plan p2 where p2.id = _plan_id_supplying and p2.owner = _user)) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': ''' + || _user ||''' is not OWNER on Plan '|| _plan_id_supplying + ||' ('|| _supplying_plan_name ||').'; + end if; + + -- PLAN_OWNER: The user must be the Owner of either Plan + elseif _permission = 'PLAN_OWNER' then + if not exists(select * + from public.plan p + where (p.id = _plan_id_receiving or p.id = _plan_id_supplying) + and p.owner = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': ''' + || _user ||''' is not PLAN_OWNER on either Plan '|| _plan_id_receiving + ||' ('|| _receiving_plan_name ||') or Plan '|| _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + end if; + + -- PLAN_COLLABORATOR: The user must be a Collaborator of either Plan. The Plan Owner is NOT considered a Collaborator of the Plan + elseif _permission = 'PLAN_COLLABORATOR' then + if not exists(select * + from public.plan_collaborators pc + where (pc.plan_id = _plan_id_receiving or pc.plan_id = _plan_id_supplying) + and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': ''' + || _user ||''' is not PLAN_COLLABORATOR on either Plan '|| _plan_id_receiving + ||' ('|| _receiving_plan_name ||') or Plan '|| _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + end if; + + -- PLAN_OWNER_COLLABORATOR: The user must be either the Owner or a Collaborator of either Plan + elseif _permission = 'PLAN_OWNER_COLLABORATOR' then + if not exists(select * + from public.plan p + where (p.id = _plan_id_receiving or p.id = _plan_id_supplying) + and p.owner = _user) then + if not exists(select * + from public.plan_collaborators pc + where (pc.plan_id = _plan_id_receiving or pc.plan_id = _plan_id_supplying) + and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': ''' + || _user ||''' is not PLAN_OWNER_COLLABORATOR on either Plan '|| _plan_id_receiving + ||' ('|| _receiving_plan_name ||') or Plan '|| _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + + end if; + end if; + + -- PLAN_OWNER_SOURCE: The user must be the Owner of the Supplying Plan + elseif _permission = 'PLAN_OWNER_SOURCE' then + if not exists(select * + from public.plan p + where p.id = _plan_id_supplying and p.owner = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER on Source Plan ' + || _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + end if; + + -- PLAN_COLLABORATOR_SOURCE: The user must be a Collaborator of the Supplying Plan. + elseif _permission = 'PLAN_COLLABORATOR_SOURCE' then + if not exists(select * + from public.plan_collaborators pc + where pc.plan_id = _plan_id_supplying and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_COLLABORATOR on Source Plan ' + || _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + end if; + + -- PLAN_OWNER_COLLABORATOR_SOURCE: The user must be either the Owner or a Collaborator of the Supplying Plan. + elseif _permission = 'PLAN_OWNER_COLLABORATOR_SOURCE' then + if not exists(select * + from public.plan p + where p.id = _plan_id_supplying and p.owner = _user) then + if not exists(select * + from public.plan_collaborators pc + where pc.plan_id = _plan_id_supplying and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER_COLLABORATOR on Source Plan ' + || _plan_id_supplying ||' ('|| _supplying_plan_name ||').'; + end if; + end if; + + -- PLAN_OWNER_TARGET: The user must be the Owner of the Receiving Plan. + elseif _permission = 'PLAN_OWNER_TARGET' then + if not exists(select * + from public.plan p + where p.id = _plan_id_receiving and p.owner = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER on Target Plan ' + || _plan_id_receiving ||' ('|| _receiving_plan_name ||').'; + end if; + + -- PLAN_COLLABORATOR_TARGET: The user must be a Collaborator of the Receiving Plan. + elseif _permission = 'PLAN_COLLABORATOR_TARGET' then + if not exists(select * + from public.plan_collaborators pc + where pc.plan_id = _plan_id_receiving and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_COLLABORATOR on Target Plan ' + || _plan_id_receiving ||' ('|| _receiving_plan_name ||').'; + end if; + + -- PLAN_OWNER_COLLABORATOR_TARGET: The user must be either the Owner or a Collaborator of the Receiving Plan. + elseif _permission = 'PLAN_OWNER_COLLABORATOR_TARGET' then + if not exists(select * + from public.plan p + where p.id = _plan_id_receiving and p.owner = _user) then + if not exists(select * + from public.plan_collaborators pc + where pc.plan_id = _plan_id_receiving and pc.collaborator = _user) then + raise insufficient_privilege + using message = 'Cannot run '''|| _function ||''': '''|| _user ||''' is not PLAN_OWNER_COLLABORATOR on Target Plan ' + || _plan_id_receiving ||' ('|| _receiving_plan_name ||').'; + end if; + end if; + end if; +end +$$; + +-- Alphabetize metadata.action_permission_key +drop type metadata.action_permission_key; +create type metadata.action_permission_key + as enum ( + 'check_constraints', + 'create_expansion_rule', + 'create_expansion_set', + 'expand_all_activities', + 'insert_ext_dataset', + 'resource_samples', + 'schedule', + 'sequence_seq_json_bulk', + 'simulate' + ); + +-- Add new key to user role +update metadata.user_role_permission + set function_permissions = function_permissions + || jsonb_build_object('create_snapshot', 'PLAN_OWNER_COLLABORATOR') + || jsonb_build_object('restore_snapshot', 'PLAN_OWNER_COLLABORATOR') +where role = 'user'; + +-- Hasura function +create table hasura_functions.create_snapshot_return_value(snapshot_id integer); +create function hasura_functions.create_snapshot(_plan_id integer, _snapshot_name text, hasura_session json) + returns hasura_functions.create_snapshot_return_value + volatile + language plpgsql as $$ +declare + _snapshot_id integer; + _snapshotter text; + _function_permission metadata.permission; +begin + _snapshotter := (hasura_session ->> 'x-hasura-user-id'); + _function_permission := metadata.get_function_permissions('create_snapshot', hasura_session); + perform metadata.raise_if_plan_merge_permission('create_snapshot', _function_permission); + if not _function_permission = 'NO_CHECK' then + call metadata.check_general_permissions('create_snapshot', _function_permission, _plan_id, _snapshotter); + end if; + if _snapshot_name is null then + raise exception 'Snapshot name cannot be null.'; + end if; + + select create_snapshot(_plan_id, _snapshot_name, _snapshotter) into _snapshot_id; + return row(_snapshot_id)::hasura_functions.create_snapshot_return_value; +end; +$$; +create function hasura_functions.restore_from_snapshot(_plan_id integer, _snapshot_id integer, hasura_session json) + returns hasura_functions.create_snapshot_return_value + volatile + language plpgsql as $$ +declare + _user text; + _function_permission metadata.permission; +begin + _user := (hasura_session ->> 'x-hasura-user-id'); + _function_permission := metadata.get_function_permissions('restore_snapshot', hasura_session); + perform metadata.raise_if_plan_merge_permission('restore_snapshot', _function_permission); + if not _function_permission = 'NO_CHECK' then + call metadata.check_general_permissions('restore_snapshot', _function_permission, _plan_id, _user); + end if; + + call restore_from_snapshot(_plan_id, _snapshot_id); + return row(_snapshot_id)::hasura_functions.create_snapshot_return_value; +end +$$; + +call migrations.mark_migration_applied('24'); diff --git a/merlin-server/sql/merlin/applied_migrations.sql b/merlin-server/sql/merlin/applied_migrations.sql index aaa1d596be..89989f2408 100644 --- a/merlin-server/sql/merlin/applied_migrations.sql +++ b/merlin-server/sql/merlin/applied_migrations.sql @@ -26,3 +26,4 @@ call migrations.mark_migration_applied('20'); call migrations.mark_migration_applied('21'); call migrations.mark_migration_applied('22'); call migrations.mark_migration_applied('23'); +call migrations.mark_migration_applied('24'); diff --git a/merlin-server/sql/merlin/domain-types/permissions.sql b/merlin-server/sql/merlin/domain-types/permissions.sql index 766fa24f94..630d89b2d5 100644 --- a/merlin-server/sql/merlin/domain-types/permissions.sql +++ b/merlin-server/sql/merlin/domain-types/permissions.sql @@ -1,15 +1,54 @@ create type metadata.permission - as enum ('NO_CHECK', 'OWNER', 'MISSION_MODEL_OWNER', 'PLAN_OWNER', 'PLAN_COLLABORATOR', 'PLAN_OWNER_COLLABORATOR', - 'PLAN_OWNER_SOURCE', 'PLAN_COLLABORATOR_SOURCE', 'PLAN_OWNER_COLLABORATOR_SOURCE', - 'PLAN_OWNER_TARGET', 'PLAN_COLLABORATOR_TARGET', 'PLAN_OWNER_COLLABORATOR_TARGET'); + as enum ( + 'NO_CHECK', + 'OWNER', + 'MISSION_MODEL_OWNER', + 'PLAN_OWNER', + 'PLAN_COLLABORATOR', + 'PLAN_OWNER_COLLABORATOR', + 'PLAN_OWNER_SOURCE', + 'PLAN_COLLABORATOR_SOURCE', + 'PLAN_OWNER_COLLABORATOR_SOURCE', + 'PLAN_OWNER_TARGET', + 'PLAN_COLLABORATOR_TARGET', + 'PLAN_OWNER_COLLABORATOR_TARGET' + ); create type metadata.action_permission_key - as enum ('simulate', 'schedule', 'insert_ext_dataset', 'check_constraints', 'create_expansion_set', - 'create_expansion_rule', 'expand_all_activities', 'sequence_seq_json_bulk', 'resource_samples'); + as enum ( + 'check_constraints', + 'create_expansion_rule', + 'create_expansion_set', + 'expand_all_activities', + 'insert_ext_dataset', + 'resource_samples', + 'schedule', + 'sequence_seq_json_bulk', + 'simulate' + ); create type metadata.function_permission_key - as enum ('apply_preset', 'branch_plan', 'create_merge_rq', 'withdraw_merge_rq', 'begin_merge', 'cancel_merge', - 'commit_merge', 'deny_merge', 'get_conflicting_activities', 'get_non_conflicting_activities', 'set_resolution', - 'set_resolution_bulk', 'delete_activity_subtree', 'delete_activity_subtree_bulk', 'delete_activity_reanchor_plan', - 'delete_activity_reanchor_plan_bulk', 'delete_activity_reanchor', 'delete_activity_reanchor_bulk', 'get_plan_history', - 'restore_activity_changelog'); + as enum ( + 'apply_preset', + 'begin_merge', + 'branch_plan', + 'cancel_merge', + 'commit_merge', + 'create_merge_rq', + 'create_snapshot', + 'delete_activity_reanchor', + 'delete_activity_reanchor_bulk', + 'delete_activity_reanchor_plan', + 'delete_activity_reanchor_plan_bulk', + 'delete_activity_subtree', + 'delete_activity_subtree_bulk', + 'deny_merge', + 'get_conflicting_activities', + 'get_non_conflicting_activities', + 'get_plan_history', + 'restore_activity_changelog', + 'restore_snapshot', + 'set_resolution', + 'set_resolution_bulk', + 'withdraw_merge_rq' + ); diff --git a/merlin-server/sql/merlin/functions/hasura/snapshot_functions.sql b/merlin-server/sql/merlin/functions/hasura/snapshot_functions.sql new file mode 100644 index 0000000000..14239a5598 --- /dev/null +++ b/merlin-server/sql/merlin/functions/hasura/snapshot_functions.sql @@ -0,0 +1,44 @@ +create table hasura_functions.create_snapshot_return_value(snapshot_id integer); +create function hasura_functions.create_snapshot(_plan_id integer, _snapshot_name text, hasura_session json) + returns hasura_functions.create_snapshot_return_value + volatile + language plpgsql as $$ +declare + _snapshot_id integer; + _snapshotter text; + _function_permission metadata.permission; +begin + _snapshotter := (hasura_session ->> 'x-hasura-user-id'); + _function_permission := metadata.get_function_permissions('create_snapshot', hasura_session); + perform metadata.raise_if_plan_merge_permission('create_snapshot', _function_permission); + if not _function_permission = 'NO_CHECK' then + call metadata.check_general_permissions('create_snapshot', _function_permission, _plan_id, _snapshotter); + end if; + if _snapshot_name is null then + raise exception 'Snapshot name cannot be null.'; + end if; + + select create_snapshot(_plan_id, _snapshot_name, _snapshotter) into _snapshot_id; + return row(_snapshot_id)::hasura_functions.create_snapshot_return_value; +end; +$$; + +create function hasura_functions.restore_from_snapshot(_plan_id integer, _snapshot_id integer, hasura_session json) + returns hasura_functions.create_snapshot_return_value + volatile + language plpgsql as $$ +declare + _user text; + _function_permission metadata.permission; +begin + _user := (hasura_session ->> 'x-hasura-user-id'); + _function_permission := metadata.get_function_permissions('restore_snapshot', hasura_session); + perform metadata.raise_if_plan_merge_permission('restore_snapshot', _function_permission); + if not _function_permission = 'NO_CHECK' then + call metadata.check_general_permissions('restore_snapshot', _function_permission, _plan_id, _user); + end if; + + call restore_from_snapshot(_plan_id, _snapshot_id); + return row(_snapshot_id)::hasura_functions.create_snapshot_return_value; +end +$$; diff --git a/merlin-server/sql/merlin/functions/public/create_snapshot.sql b/merlin-server/sql/merlin/functions/public/create_snapshot.sql index e348b1011e..68ebc1e490 100644 --- a/merlin-server/sql/merlin/functions/public/create_snapshot.sql +++ b/merlin-server/sql/merlin/functions/public/create_snapshot.sql @@ -1,5 +1,13 @@ -- Captures the state of a plan and all of its activities create function create_snapshot(_plan_id integer) + returns integer + language plpgsql as $$ +begin + return create_snapshot(_plan_id, null, null); +end +$$; + +create function create_snapshot(_plan_id integer, _user text, _snapshot_name text) returns integer -- snapshot id inserted into the table language plpgsql as $$ declare @@ -11,18 +19,19 @@ begin raise exception 'Plan % does not exist.', _plan_id; end if; - insert into plan_snapshot(plan_id, revision, name, duration, start_time) - select id, revision, name, duration, start_time + insert into plan_snapshot(plan_id, revision, snapshot_name, taken_by) + select id, revision, _snapshot_name, _user from plan where id = _plan_id returning snapshot_id into inserted_snapshot_id; insert into plan_snapshot_activities( - snapshot_id, id, name, source_scheduling_goal_id, created_at, - last_modified_at, last_modified_by, start_offset, type, - arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start) + snapshot_id, id, name, source_scheduling_goal_id, created_at, + last_modified_at, last_modified_by, start_offset, type, + arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start) select inserted_snapshot_id, -- this is the snapshot id id, name, source_scheduling_goal_id, created_at, -- these are the rest of the data for an activity row - last_modified_at, last_modified_by, start_offset, type, arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start + last_modified_at, last_modified_by, start_offset, type, + arguments, last_modified_arguments_at, metadata, anchor_id, anchored_to_start from activity_directive where activity_directive.plan_id = _plan_id; insert into preset_to_snapshot_directive(preset_id, activity_id, snapshot_id) select ptd.preset_id, ptd.activity_id, inserted_snapshot_id @@ -47,8 +56,13 @@ begin $$; comment on function create_snapshot(integer) is e'' + 'See comment on create_snapshot(integer, text, text)'; + +comment on function create_snapshot(integer, text, text) is e'' 'Create a snapshot of the specified plan. A snapshot consists of:' - ' - The plan''s name, revision, duration, start time, and id' + ' - The plan''s id and revision' ' - All the activities in the plan' ' - The preset status of those activities' - ' - The tags on those activities'; + ' - The tags on those activities' + ' - When the snapshot was taken' + ' - Optionally: who took the snapshot and a name'; diff --git a/merlin-server/sql/merlin/functions/public/restore_from_snapshot.sql b/merlin-server/sql/merlin/functions/public/restore_from_snapshot.sql new file mode 100644 index 0000000000..6851568dea --- /dev/null +++ b/merlin-server/sql/merlin/functions/public/restore_from_snapshot.sql @@ -0,0 +1,105 @@ +create procedure restore_from_snapshot(_plan_id integer, _snapshot_id integer) + language plpgsql as $$ + declare + _snapshot_name text; + _plan_name text; + begin + -- Input Validation + select name from plan where id = _plan_id into _plan_name; + if _plan_name is null then + raise exception 'Cannot Restore: Plan with ID % does not exist.', _plan_id; + end if; + if not exists(select snapshot_id from plan_snapshot where snapshot_id = _snapshot_id) then + raise exception 'Cannot Restore: Snapshot with ID % does not exist.', _snapshot_id; + end if; + if not exists(select snapshot_id from plan_snapshot where _snapshot_id = snapshot_id and _plan_id = plan_id ) then + select snapshot_name from plan_snapshot where snapshot_id = _snapshot_id into _snapshot_name; + if _snapshot_name is not null then + raise exception 'Cannot Restore: Snapshot ''%'' (ID %) is not a snapshot of Plan ''%'' (ID %)', + _snapshot_name, _snapshot_id, _plan_name, _plan_id; + else + raise exception 'Cannot Restore: Snapshot % is not a snapshot of Plan ''%'' (ID %)', + _snapshot_id, _plan_name, _plan_id; + end if; + end if; + + -- Catch Plan_Locked + call plan_locked_exception(_plan_id); + + -- Record the Union of Activities in Plan and Snapshot + -- and note which ones have been added since the Snapshot was taken (in_snapshot = false) + create temp table diff( + activity_id integer, + in_snapshot boolean not null + ); + insert into diff(activity_id, in_snapshot) + select id as activity_id, true + from plan_snapshot_activities where snapshot_id = _snapshot_id; + + insert into diff (activity_id, in_snapshot) + select activity_id, false + from( + select id as activity_id + from activity_directive + where plan_id = _plan_id + except + select activity_id + from diff) a; + + -- Remove any added activities + delete from activity_directive ad + using diff d + where (ad.id, ad.plan_id) = (d.activity_id, _plan_id) + and d.in_snapshot is false; + + -- Upsert the rest + insert into activity_directive ( + id, plan_id, name, source_scheduling_goal_id, created_at, last_modified_at, last_modified_by, + start_offset, type, arguments, last_modified_arguments_at, metadata, + anchor_id, anchored_to_start) + select psa.id, _plan_id, psa.name, psa.source_scheduling_goal_id, psa.created_at, psa.last_modified_at, psa.last_modified_by, + psa.start_offset, psa.type, psa.arguments, psa.last_modified_arguments_at, psa.metadata, + psa.anchor_id, psa.anchored_to_start + from plan_snapshot_activities psa + where psa.snapshot_id = _snapshot_id + on conflict (id, plan_id) do update + -- 'last_modified_at' and 'last_modified_arguments_at' are skipped during update, as triggers will overwrite them to now() + set name = excluded.name, + source_scheduling_goal_id = excluded.source_scheduling_goal_id, + created_at = excluded.created_at, + last_modified_by = excluded.last_modified_by, + start_offset = excluded.start_offset, + type = excluded.type, + arguments = excluded.arguments, + metadata = excluded.metadata, + anchor_id = excluded.anchor_id, + anchored_to_start = excluded.anchored_to_start; + + -- Tags + delete from metadata.activity_directive_tags adt + using diff d + where (adt.directive_id, adt.plan_id) = (d.activity_id, _plan_id); + + insert into metadata.activity_directive_tags(directive_id, plan_id, tag_id) + select sat.directive_id, _plan_id, sat.tag_id + from metadata.snapshot_activity_tags sat + where sat.snapshot_id = _snapshot_id + on conflict (directive_id, plan_id, tag_id) do nothing; + + -- Presets + delete from preset_to_directive + where plan_id = _plan_id; + insert into preset_to_directive(preset_id, activity_id, plan_id) + select pts.preset_id, pts.activity_id, _plan_id + from preset_to_snapshot_directive pts + where pts.snapshot_id = _snapshot_id + on conflict (activity_id, plan_id) + do update set preset_id = excluded.preset_id; + + -- Clean up + drop table diff; + end +$$; + +comment on procedure restore_from_snapshot(_plan_id integer, _snapshot_id integer) is e'' + 'Restore a plan to its state described in the given snapshot.'; diff --git a/merlin-server/sql/merlin/init.sql b/merlin-server/sql/merlin/init.sql index 88e57ca3fa..29a0a652d1 100644 --- a/merlin-server/sql/merlin/init.sql +++ b/merlin-server/sql/merlin/init.sql @@ -75,6 +75,7 @@ begin; \ir functions/public/begin_merge.sql \ir functions/public/commit_merge.sql \ir functions/public/create_snapshot.sql + \ir functions/public/restore_from_snapshot.sql -- Presets \ir tables/activity_presets.sql @@ -99,6 +100,7 @@ begin; -- Hasura Functions \ir functions/hasura/activity_preset_functions.sql + \ir functions/hasura/snapshot_functions.sql \ir functions/hasura/delete_anchor_functions.sql \ir functions/hasura/hasura_functions.sql \ir functions/hasura/plan_branching_functions.sql diff --git a/merlin-server/sql/merlin/tables/metadata/user_role_permission.sql b/merlin-server/sql/merlin/tables/metadata/user_role_permission.sql index a65cb541f7..5f7e1f2083 100644 --- a/merlin-server/sql/merlin/tables/metadata/user_role_permission.sql +++ b/merlin-server/sql/merlin/tables/metadata/user_role_permission.sql @@ -25,42 +25,44 @@ values ('aerie_admin', '{}', '{}'), ('user', '{ - "simulate":"PLAN_OWNER_COLLABORATOR", - "schedule":"PLAN_OWNER_COLLABORATOR", - "insert_ext_dataset": "PLAN_OWNER", "check_constraints": "PLAN_OWNER_COLLABORATOR", - "create_expansion_set": "NO_CHECK", "create_expansion_rule": "NO_CHECK", + "create_expansion_set": "NO_CHECK", "expand_all_activities": "NO_CHECK", + "insert_ext_dataset": "PLAN_OWNER", "resource_samples": "NO_CHECK", - "sequence_seq_json_bulk": "NO_CHECK" + "schedule":"PLAN_OWNER_COLLABORATOR", + "sequence_seq_json_bulk": "NO_CHECK", + "simulate":"PLAN_OWNER_COLLABORATOR" }', '{ "apply_preset": "PLAN_OWNER_COLLABORATOR", - "branch_plan": "NO_CHECK", - "create_merge_rq": "PLAN_OWNER_SOURCE", - "withdraw_merge_rq": "PLAN_OWNER_SOURCE", "begin_merge": "PLAN_OWNER_TARGET", + "branch_plan": "NO_CHECK", "cancel_merge": "PLAN_OWNER_TARGET", "commit_merge": "PLAN_OWNER_TARGET", + "create_merge_rq": "PLAN_OWNER_SOURCE", + "create_snapshot": "PLAN_OWNER_COLLABORATOR", + "delete_activity_reanchor": "PLAN_OWNER_COLLABORATOR", + "delete_activity_reanchor_bulk": "PLAN_OWNER_COLLABORATOR", + "delete_activity_reanchor_plan": "PLAN_OWNER_COLLABORATOR", + "delete_activity_reanchor_plan_bulk": "PLAN_OWNER_COLLABORATOR", + "delete_activity_subtree": "PLAN_OWNER_COLLABORATOR", + "delete_activity_subtree_bulk": "PLAN_OWNER_COLLABORATOR", "deny_merge": "PLAN_OWNER_TARGET", "get_conflicting_activities": "NO_CHECK", "get_non_conflicting_activities": "NO_CHECK", + "get_plan_history": "NO_CHECK", + "restore_activity_changelog": "PLAN_OWNER_COLLABORATOR", + "restore_snapshot": "PLAN_OWNER_COLLABORATOR", "set_resolution": "PLAN_OWNER_TARGET", "set_resolution_bulk": "PLAN_OWNER_TARGET", - "delete_activity_subtree": "PLAN_OWNER_COLLABORATOR", - "delete_activity_subtree_bulk": "PLAN_OWNER_COLLABORATOR", - "delete_activity_reanchor_plan": "PLAN_OWNER_COLLABORATOR", - "delete_activity_reanchor_plan_bulk": "PLAN_OWNER_COLLABORATOR", - "delete_activity_reanchor": "PLAN_OWNER_COLLABORATOR", - "delete_activity_reanchor_bulk": "PLAN_OWNER_COLLABORATOR", - "get_plan_history": "NO_CHECK", - "restore_activity_changelog": "PLAN_OWNER_COLLABORATOR" + "withdraw_merge_rq": "PLAN_OWNER_SOURCE" }' ), ('viewer', '{ - "resource_samples": "NO_CHECK", - "sequence_seq_json_bulk": "NO_CHECK" + "sequence_seq_json_bulk": "NO_CHECK", + "resource_samples": "NO_CHECK" }', '{ "get_conflicting_activities": "NO_CHECK", diff --git a/merlin-server/sql/merlin/tables/plan_snapshot.sql b/merlin-server/sql/merlin/tables/plan_snapshot.sql index 859bab6cca..65be5cfb00 100644 --- a/merlin-server/sql/merlin/tables/plan_snapshot.sql +++ b/merlin-server/sql/merlin/tables/plan_snapshot.sql @@ -1,5 +1,5 @@ -- Snapshot is a collection of the state of all the activities as they were at the time of the snapshot --- as well as any other properties of the plan that can change +-- as well as other of the plan metadata create table plan_snapshot( snapshot_id integer generated always as identity @@ -8,12 +8,26 @@ create table plan_snapshot( plan_id integer references plan on delete set null, - revision integer not null, - name text not null, - duration interval not null, - start_time timestamptz not null + + snapshot_name text, + taken_by text, + taken_at timestamptz not null default now(), + constraint snapshot_name_unique_per_plan + unique (plan_id, snapshot_name) ); comment on table plan_snapshot is e'' - 'A record of the metadata associated with a plan, excluding tags.'; + 'A record of the state of a plan at a given time.'; +comment on column plan_snapshot.snapshot_id is e'' + 'The identifier of the snapshot.'; +comment on column plan_snapshot.plan_id is e'' + 'The plan that this is a snapshot of.'; +comment on column plan_snapshot.revision is e'' + 'The revision of the plan at the time the snapshot was taken.'; +comment on column plan_snapshot.snapshot_name is e'' + 'A human-readable name for the snapshot.'; +comment on column plan_snapshot.taken_by is e'' + 'The user who took the snapshot.'; +comment on column plan_snapshot.taken_at is e'' + 'The time that the snapshot was taken.';