Skip to content

Commit

Permalink
feat: updated postman, moved trigger construction to migration, added…
Browse files Browse the repository at this point in the history
… unit tests
  • Loading branch information
OddTomBrooks committed Dec 11, 2024
1 parent edd4844 commit 3c2991e
Show file tree
Hide file tree
Showing 4 changed files with 221 additions and 93 deletions.
21 changes: 21 additions & 0 deletions MINT.postman_collection.json
Original file line number Diff line number Diff line change
Expand Up @@ -2909,6 +2909,27 @@
},
"response": []
},
{
"name": "DeleteMTOCategory",
"request": {
"method": "POST",
"header": [],
"body": {
"mode": "graphql",
"graphql": {
"query": "mutation {\n deleteMTOCategory(id: \"{{mtoCategoryID}}\")\n}",
"variables": ""
}
},
"url": {
"raw": "{{url}}",
"host": [
"{{url}}"
]
}
},
"response": []
},
{
"name": "4 MTO Categories",
"event": [
Expand Down
89 changes: 89 additions & 0 deletions migrations/V193__Add_MTO_Category_Delete_Trigger.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,89 @@
/*
This SQL script sets up a trigger and a supporting function to handle custom cascading
deletion behavior for categories in the `mto_category` table, per the application requirements.
Updated Assumption (per user's note):
-------------------------------------
Instead of assigning milestones to a designated "Uncategorized" category with a known UUID,
we will set their `mto_category_id` to NULL (a "nil" UUID), indicating they are now uncategorized.
Requirements:
- Deleting a subcategory:
* All milestones referencing that subcategory should be reassigned to its parent category.
- Deleting a top-level category:
* All milestones referencing the deleted top-level category or its direct subcategories
should have `mto_category_id` set to NULL, indicating they are now uncategorized.
* All direct subcategories of the deleted category should be deleted.
Why the "CASCADE" Keyword Isn't Used:
-------------------------------------
The standard ON DELETE CASCADE simply removes dependent rows. Here, we need to reassign
references rather than just delete them. Since this behavior is more complex, we implement
custom logic in a trigger and a PL/pgSQL function rather than relying on cascade deletes.
Usage:
- Once this script is applied, a `DELETE FROM mto_category WHERE id = 'some-category-uuid';`
will trigger the logic to reassign milestones and remove subcategories as defined.
Assumptions:
- When deleting a top-level category, milestones are "uncategorized" by setting their
`mto_category_id` to NULL.
- For subcategories, milestones are moved up to the parent category.
- This handles one level of subcategories. If a deeper hierarchy is required,
the logic should be extended to recursively handle all descendants.
*/

-- Drop existing trigger and function to allow clean re-creation
DROP TRIGGER IF EXISTS mto_category_before_delete ON mto_category;
DROP FUNCTION IF EXISTS rebalance_milestones_before_category_delete();

-- Create the trigger function that implements the custom cascading logic
CREATE OR REPLACE FUNCTION rebalance_milestones_before_category_delete()
RETURNS TRIGGER AS $$
DECLARE
cat_model_plan_id UUID;
is_top_level BOOLEAN;
BEGIN
-- Determine if the category is top-level or a subcategory
SELECT model_plan_id, (parent_id IS NULL) INTO cat_model_plan_id, is_top_level
FROM mto_category
WHERE id = OLD.id;

IF is_top_level THEN
-- TOP-LEVEL CATEGORY DELETION LOGIC:
-- Reassign all milestones referencing this category or its direct subcategories
-- to NULL, marking them as uncategorized.

UPDATE mto_milestone
SET mto_category_id = NULL
WHERE mto_category_id IN (
SELECT id FROM mto_category
WHERE parent_id = OLD.id
UNION ALL
SELECT OLD.id
);

-- Delete all direct subcategories of this category
DELETE FROM mto_category
WHERE parent_id = OLD.id;

-- The category itself (OLD.id) will be deleted by the original DELETE statement
ELSE
-- SUBCATEGORY DELETION LOGIC:
-- Move all milestones from this subcategory to its parent category
UPDATE mto_milestone
SET mto_category_id = OLD.parent_id
WHERE mto_category_id = OLD.id;

-- The subcategory (OLD.id) will be deleted by the original DELETE statement
END IF;

RETURN OLD; -- Allow the DELETE to proceed after adjustments
END;
$$ LANGUAGE plpgsql;

-- Create the trigger to invoke the above function before any category deletion
CREATE TRIGGER mto_category_before_delete
BEFORE DELETE ON mto_category
FOR EACH ROW
EXECUTE FUNCTION rebalance_milestones_before_category_delete();
111 changes: 111 additions & 0 deletions pkg/graph/resolvers/mto_category_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -672,3 +672,114 @@ func (suite *ResolverSuite) TestMTOCreateStandardCategories() {
suite.Equal(9, numCategories) // just top-level categories (one more than before)
suite.Equal(12, numSubcategories) // just subcategories (two more than before)
}

func (suite *ResolverSuite) TestMTOCategoryDelete_NullID() {
// Attempt to delete a category using a null (uuid.Nil) ID
// Expectation: This should return an error indicating the category does not exist or invalid input.

invalidID := uuid.Nil
err := MTOCategoryDelete(suite.testConfigs.Context, suite.testConfigs.Logger, suite.testConfigs.Principal, suite.testConfigs.Store, invalidID)
suite.Error(err, "Deleting a category with a null (uuid.Nil) ID should result in an error")
}

func (suite *ResolverSuite) TestMTOCategoryDelete_NoMilestones() {
// Create a top-level category with no subcategories and no milestones.
// Deleting it should work cleanly and simply remove the category.
// Expectation: No error on deletion, and the category should no longer be retrievable.

plan := suite.createModelPlan("Test Deletion Without Milestones")
category := suite.createMTOCategory("No Milestones Category", plan.ID, nil)

// Confirm category is retrievable before deletion
catBeforeDelete, err := MTOCategoryGetByID(suite.testConfigs.Context, category.ID)
suite.NoError(err)
suite.Equal(category.ID, catBeforeDelete.ID, "Category should exist before deletion")

// Delete the category
err = MTOCategoryDelete(suite.testConfigs.Context, suite.testConfigs.Logger, suite.testConfigs.Principal, suite.testConfigs.Store, category.ID)
suite.NoError(err, "Deleting a category with no milestones should succeed")

// Confirm category no longer exists
catAfterDelete, err := MTOCategoryGetByID(suite.testConfigs.Context, category.ID)
suite.Error(err, "Category should not be found after deletion")
suite.Nil(catAfterDelete, "Category should be nil after deletion")
}

func (suite *ResolverSuite) TestMTOCategoryDelete_TopLevelCategory() {
// Create a top-level category with subcategories and milestones.
// On delete:
// - All milestones referencing this top-level category and its subcategories should be uncategorized (mto_category_id = NULL).
// - All direct subcategories should be deleted.
// Expectation:
// - No error on deletion.
// - Check milestones are now uncategorized.
// - Check subcategories are deleted.

plan := suite.createModelPlan("Test Top-Level Deletion")
topCategory := suite.createMTOCategory("Top Category To Delete", plan.ID, nil)

// Create subcategories
subCatNames := []string{"SubCat A", "SubCat B"}
subCategories := suite.createMultipleMTOcategories(subCatNames, plan.ID, &topCategory.ID)

// Create a milestone in the top-level category
milestoneTop, err := MTOMilestoneCreateCustom(suite.testConfigs.Context, suite.testConfigs.Logger, suite.testConfigs.Principal, suite.testConfigs.Store, "Milestone in Top", plan.ID, &topCategory.ID)
suite.NoError(err)

// Create a milestone in a subcategory
milestoneSub, err := MTOMilestoneCreateCustom(suite.testConfigs.Context, suite.testConfigs.Logger, suite.testConfigs.Principal, suite.testConfigs.Store, "Milestone in Sub", plan.ID, &subCategories[0].ID)
suite.NoError(err)

// Delete the top-level category
err = MTOCategoryDelete(suite.testConfigs.Context, suite.testConfigs.Logger, suite.testConfigs.Principal, suite.testConfigs.Store, topCategory.ID)
suite.NoError(err, "Deleting a top-level category should succeed")

// Verify top-level category and its subcategories no longer exist
_, err = MTOCategoryGetByID(suite.testConfigs.Context, topCategory.ID)
suite.Error(err, "Top-level category should not exist after deletion")

for _, sc := range subCategories {
_, err := MTOCategoryGetByID(suite.testConfigs.Context, sc.ID)
suite.Error(err, "Subcategory should not exist after top-level category deletion")
}

// Verify milestones are now uncategorized
milestoneTopAfter, err := MTOMilestoneGetByIDLOADER(suite.testConfigs.Context, milestoneTop.ID)
suite.NoError(err)
suite.Nil(milestoneTopAfter.MTOCategoryID, "Milestone that was in the top-level category should now be uncategorized")

milestoneSubAfter, err := MTOMilestoneGetByIDLOADER(suite.testConfigs.Context, milestoneSub.ID)
suite.NoError(err)
suite.Nil(milestoneSubAfter.MTOCategoryID, "Milestone that was in a subcategory should now be uncategorized")
}

func (suite *ResolverSuite) TestMTOCategoryDelete_SubCategory() {
// Create a top-level category and a single subcategory with milestones.
// On deleting the subcategory:
// - All milestones referencing that subcategory should be reassigned to the parent category.
// Expectation:
// - No error on deletion.
// - Subcategory is deleted.
// - Milestones previously in the subcategory now reference the parent category.

plan := suite.createModelPlan("Test Subcategory Deletion")
parentCategory := suite.createMTOCategory("Parent Category", plan.ID, nil)
subCategory := suite.createMTOCategory("SubCategory To Delete", plan.ID, &parentCategory.ID)

// Create a milestone in the subcategory
milestoneSub, err := MTOMilestoneCreateCustom(suite.testConfigs.Context, suite.testConfigs.Logger, suite.testConfigs.Principal, suite.testConfigs.Store, "SubCategory Milestone", plan.ID, &subCategory.ID)
suite.NoError(err)

// Delete the subcategory
err = MTOCategoryDelete(suite.testConfigs.Context, suite.testConfigs.Logger, suite.testConfigs.Principal, suite.testConfigs.Store, subCategory.ID)
suite.NoError(err, "Deleting a subcategory should succeed")

// Verify subcategory no longer exists
_, err = MTOCategoryGetByID(suite.testConfigs.Context, subCategory.ID)
suite.Error(err, "Subcategory should not exist after deletion")

// Verify milestone has been reassigned to parent category
milestoneSubAfter, err := MTOMilestoneGetByIDLOADER(suite.testConfigs.Context, milestoneSub.ID)
suite.NoError(err)
suite.Equal(parentCategory.ID, *milestoneSubAfter.MTOCategoryID, "Milestone should now reference the parent category after subcategory deletion")
}
93 changes: 0 additions & 93 deletions pkg/sqlqueries/SQL/mto/category/delete.sql
Original file line number Diff line number Diff line change
@@ -1,96 +1,3 @@
-- TODO: Move function creation to a migration, keeping it here for testing purposes

/*
This SQL script sets up a trigger and a supporting function to handle custom cascading
deletion behavior for categories in the `mto_category` table, per the application requirements.
Updated Assumption (per user's note):
-------------------------------------
Instead of assigning milestones to a designated "Uncategorized" category with a known UUID,
we will set their `mto_category_id` to NULL (a "nil" UUID), indicating they are now uncategorized.
Requirements:
- Deleting a subcategory:
* All milestones referencing that subcategory should be reassigned to its parent category.
- Deleting a top-level category:
* All milestones referencing the deleted top-level category or its direct subcategories
should have `mto_category_id` set to NULL, indicating they are now uncategorized.
* All direct subcategories of the deleted category should be deleted.
Why the "CASCADE" Keyword Isn't Used:
-------------------------------------
The standard ON DELETE CASCADE simply removes dependent rows. Here, we need to reassign
references rather than just delete them. Since this behavior is more complex, we implement
custom logic in a trigger and a PL/pgSQL function rather than relying on cascade deletes.
Usage:
- Once this script is applied, a `DELETE FROM mto_category WHERE id = 'some-category-uuid';`
will trigger the logic to reassign milestones and remove subcategories as defined.
Assumptions:
- When deleting a top-level category, milestones are "uncategorized" by setting their
`mto_category_id` to NULL.
- For subcategories, milestones are moved up to the parent category.
- This handles one level of subcategories. If a deeper hierarchy is required,
the logic should be extended to recursively handle all descendants.
*/

-- Drop existing trigger and function to allow clean re-creation
DROP TRIGGER IF EXISTS mto_category_before_delete ON mto_category;
DROP FUNCTION IF EXISTS rebalance_milestones_before_category_delete();

-- Create the trigger function that implements the custom cascading logic
CREATE OR REPLACE FUNCTION rebalance_milestones_before_category_delete()
RETURNS TRIGGER AS $$
DECLARE
cat_model_plan_id UUID;
is_top_level BOOLEAN;
BEGIN
-- Determine if the category is top-level or a subcategory
SELECT model_plan_id, (parent_id IS NULL) INTO cat_model_plan_id, is_top_level
FROM mto_category
WHERE id = OLD.id;

IF is_top_level THEN
-- TOP-LEVEL CATEGORY DELETION LOGIC:
-- Reassign all milestones referencing this category or its direct subcategories
-- to NULL, marking them as uncategorized.

UPDATE mto_milestone
SET mto_category_id = NULL
WHERE mto_category_id IN (
SELECT id FROM mto_category
WHERE parent_id = OLD.id
UNION ALL
SELECT OLD.id
);

-- Delete all direct subcategories of this category
DELETE FROM mto_category
WHERE parent_id = OLD.id;

-- The category itself (OLD.id) will be deleted by the original DELETE statement
ELSE
-- SUBCATEGORY DELETION LOGIC:
-- Move all milestones from this subcategory to its parent category
UPDATE mto_milestone
SET mto_category_id = OLD.parent_id
WHERE mto_category_id = OLD.id;

-- The subcategory (OLD.id) will be deleted by the original DELETE statement
END IF;

RETURN OLD; -- Allow the DELETE to proceed after adjustments
END;
$$ LANGUAGE plpgsql;

-- Create the trigger to invoke the above function before any category deletion
CREATE TRIGGER mto_category_before_delete
BEFORE DELETE ON mto_category
FOR EACH ROW
EXECUTE FUNCTION rebalance_milestones_before_category_delete();


DELETE FROM mto_category
WHERE id = :id
RETURNING
Expand Down

0 comments on commit 3c2991e

Please sign in to comment.