Skip to content
This repository has been archived by the owner on Mar 11, 2021. It is now read-only.

Commit

Permalink
Write migration test
Browse files Browse the repository at this point in the history
  • Loading branch information
kwk committed Oct 23, 2018
1 parent aa5f94a commit 78a0143
Show file tree
Hide file tree
Showing 6 changed files with 264 additions and 2 deletions.
4 changes: 2 additions & 2 deletions docs/cascading-soft-delete.md
Original file line number Diff line number Diff line change
Expand Up @@ -240,8 +240,8 @@ What applies to areas also applies to iterations, labels and board columns as we
Steps

1. Create "*_archived" tables for all tables that inherit the original tables.
2. Move all entries where `deleted_at` IS NOT NULL to their respective `_archive` table.
3. Install a soft-delete trigger usinge the above `archive_record()` function.
2. Install a soft-delete trigger usinge the above `archive_record()` function.
3. Move all entries where `deleted_at IS NOT NULL` to their respective `_archive` table by doing a hard `DELETE` which will trigger the `archive_record()` function.

# Example

Expand Down
3 changes: 3 additions & 0 deletions migration/migration.go
Original file line number Diff line number Diff line change
Expand Up @@ -468,6 +468,9 @@ func GetMigrations() Migrations {
// Version 110
m = append(m, steps{ExecuteSQLFile("110-update-number-for-existing-iterations.sql")})

// Version 111
m = append(m, steps{ExecuteSQLFile("111-cascading-soft-delete.sql")})

// Version N
//
// In order to add an upgrade, simply append an array of MigrationFunc to the
Expand Down
110 changes: 110 additions & 0 deletions migration/migration_blackbox_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -160,6 +160,7 @@ func TestMigrations(t *testing.T) {
t.Run("TestMirgraion108", testMigration108NumberColumnForArea)
t.Run("TestMirgraion109", testMigration109NumberColumnForIteration)
t.Run("TestMirgraion110", testMigration110UpdateNumberForExistingIterations)
t.Run("TestMirgraion111", testMigration111CascadingSoftDelete)

// Perform the migration
err = migration.Migrate(sqlDB, databaseName)
Expand Down Expand Up @@ -1461,6 +1462,115 @@ func testMigration110UpdateNumberForExistingIterations(t *testing.T) {
})
}

func testMigration111CascadingSoftDelete(t *testing.T) {
t.Run("migrate to previous version", func(t *testing.T) {
migrateToVersion(t, sqlDB, migrations[:111], 111)
})

areaDeletedID := uuid.NewV4()
areaID := uuid.NewV4()
commentDeletedID := uuid.NewV4()
commentID := uuid.NewV4()
iterDeletedID := uuid.NewV4()
iterID := uuid.NewV4()
labelDeletedID := uuid.NewV4()
labelID := uuid.NewV4()
spaceDeletedID := uuid.NewV4()
spaceID := uuid.NewV4()
spaceTemplateDeletedID := uuid.NewV4()
spaceTemplateID := uuid.NewV4()
workItemDeletedID := uuid.NewV4()
workItemID := uuid.NewV4()
workItemLinkDeletedID := uuid.NewV4()
workItemLinkID := uuid.NewV4()
workItemLinkTypeDeletedID := uuid.NewV4()
workItemLinkTypeID := uuid.NewV4()
workItemTypeDeletedID := uuid.NewV4()
workItemTypeID := uuid.NewV4()

t.Run("setup test data to migrate", func(t *testing.T) {
require.Nil(t, runSQLscript(sqlDB, "111-cascading-soft-delete.sql",
areaID,
areaDeletedID,
commentDeletedID,
commentID,
iterID,
iterDeletedID,
labelID,
labelDeletedID,
spaceID,
spaceDeletedID,
spaceTemplateID,
spaceTemplateDeletedID,
workItemID,
workItemDeletedID,
workItemLinkID,
workItemLinkDeletedID,
workItemLinkTypeID,
workItemLinkTypeDeletedID,
workItemTypeID,
workItemTypeDeletedID,
))
})

// Helper functions
exists := func(t *testing.T, table string, id uuid.UUID) bool {
q := fmt.Sprintf("SELECT 1 FROM %s WHERE id = '%s'", table, id)
row := sqlDB.QueryRow(q)
require.NotNil(t, row)
var p int32
err := row.Scan(&p)
require.NoError(t, err, "%+v", err)
return p == 1
}
existsButIsDeleted := func(t *testing.T, table string, id uuid.UUID) bool {
q := fmt.Sprintf("SELECT 1 FROM %s WHERE id = '%s' AND deleted_at IS NOT NULL", table, id)
row := sqlDB.QueryRow(q)
require.NotNil(t, row)
var p int32
err := row.Scan(&p)
require.NoError(t, err, "%+v", err)
return p == 1
}
checkEntitiesExist := func(t *testing.T, existFunc func(t *testing.T, table string, id uuid.UUID) bool) {
t.Run("check that all entities exist", func(t *testing.T) {
require.True(t, existFunc(t, "areas", areaID))
require.True(t, existsButIsDeleted(t, "areas", areaDeletedID))
require.True(t, existFunc(t, "work_item_comments", commentID))
require.True(t, existsButIsDeleted(t, "work_item_comments", commentDeletedID))
require.True(t, existFunc(t, "iterations", iterID))
require.True(t, existsButIsDeleted(t, "iterations", iterDeletedID))
require.True(t, existFunc(t, "labels", labelID))
require.True(t, existsButIsDeleted(t, "labels", labelDeletedID))
require.True(t, existFunc(t, "spaces", spaceID))
require.True(t, existsButIsDeleted(t, "spaces", spaceDeletedID))
require.True(t, existFunc(t, "space_templates", spaceTemplateID))
require.True(t, existsButIsDeleted(t, "space_templates", spaceTemplateDeletedID))
require.True(t, existFunc(t, "work_items", workItemID))
require.True(t, existsButIsDeleted(t, "work_items", workItemDeletedID))
require.True(t, existFunc(t, "work_item_links", workItemLinkID))
require.True(t, existsButIsDeleted(t, "work_item_links", workItemLinkDeletedID))
require.True(t, existFunc(t, "work_item_link_types", workItemLinkTypeID))
require.True(t, existsButIsDeleted(t, "work_item_link_types", workItemLinkTypeDeletedID))
require.True(t, existFunc(t, "work_item_types", workItemTypeID))
require.True(t, existsButIsDeleted(t, "work_item_types", workItemTypeDeletedID))
})
})

t.Run("before migration", func(t *testing.T) {
checkEntitiesExist(t, exists)
})
t.Run("migrate to current version", func(t *testing.T) {
migrateToVersion(t, sqlDB, migrations[:112], 112)
})
t.Run("after migration", func(t *testing.T) {
checkEntitiesExist(t, exists)
require.Nil(t, runSQLscript(sqlDB, "111-soft-delete-space-template.sql", spaceTemplateID))
checkEntitiesExist(t, existsButIsDeleted)
})

}

// runSQLscript loads the given filename from the packaged SQL test files and
// executes it on the given database. Golang text/template module is used
// to handle all the optional arguments passed to the sql test files
Expand Down
89 changes: 89 additions & 0 deletions migration/sql-files/111-cascading-soft-delete.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,89 @@
CREATE OR REPLACE FUNCTION archive_record()
-- archive_record() can be use used as the trigger function on all tables
-- that want to archive their data into a separate *_archive table after
-- it was (soft-)DELETEd on the main table. The function will have no effect
-- if it is being used on a non-DELETE or non-UPDATE trigger.
--
-- You should set up a trigger like so:
--
-- CREATE TRIGGER soft_delete_countries
-- AFTER
-- -- this is what is triggered by GORM
-- UPDATE OF deleted_at
-- -- this is what is triggered by a cascaded DELETE or a direct hard-DELETE
-- OR DELETE
-- ON countries
-- FOR EACH ROW
-- EXECUTE PROCEDURE archive_record();
--
-- The effect of such a trigger is that your entry will be archived under
-- these circumstances:
--
-- 1. a soft-delete happens by setting a row's `deleted_at` field to a non-`NULL` value,
-- 2. a hard-DELETE happens,
-- 3. or a cascaded DELETE happens that was triggered by one of the before mentioned events.
--
-- The only requirements are:
--
-- 1. your table has a `deleted_at` field
-- 2. your table has an archive table with the extact same name and an `_archive` suffix
-- 3. your table has a primary key called `id`
--
-- You should set up your archive table like so:
--
-- CREATE TABLE your_table_archive (CHECK(deleted_at IS NOT NULL)) INHERITS(your_table);
RETURNS TRIGGER AS $$
BEGIN
-- When a soft-delete happens
IF (TG_OP = 'UPDATE' AND NEW.deleted_at IS NOT NULL) THEN
EXECUTE format('DELETE FROM %I.%I WHERE id = $1', TG_TABLE_SCHEMA, TG_TABLE_NAME) USING OLD.id;
RETURN OLD;
END IF;
-- When a hard-DELETE or a cascaded delete happens
IF (TG_OP = 'DELETE') THEN
-- Set the time when the deletion happen (if not already done)
IF (OLD.deleted_at IS NULL) THEN
OLD.deleted_at := timenow();
END IF;
EXECUTE format('INSERT INTO %I.%I SELECT $1.*', TG_TABLE_SCHEMA, TG_TABLE_NAME || '_archive')
USING OLD;
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;

-- Create archive tables
CREATE TABLE areas_archive (CHECK (deleted_at IS NOT NULL)) INHERITS (areas);
CREATE TABLE comments_archive (CHECK (deleted_at IS NOT NULL)) INHERITS (comments);
CREATE TABLE iterations_archive (CHECK (deleted_at IS NOT NULL)) INHERITS (iterations);
CREATE TABLE labels_archive (CHECK (deleted_at IS NOT NULL)) INHERITS (lables);
CREATE TABLE space_templates_archive (CHECK (deleted_at IS NOT NULL)) INHERITS (space_templates);
CREATE TABLE spaces_archive (CHECK (deleted_at IS NOT NULL)) INHERITS (spaces);
CREATE TABLE work_item_link_types_archive (CHECK (deleted_at IS NOT NULL)) INHERITS (work_item_link_types);
CREATE TABLE work_item_links_archive (CHECK (deleted_at IS NOT NULL)) INHERITS (work_item_links);
CREATE TABLE work_item_types_archive (CHECK (deleted_at IS NOT NULL)) INHERITS (work_item_types);
CREATE TABLE work_items_archive (CHECK (deleted_at IS NOT NULL)) INHERITS (work_items);

-- Setup triggers
CREATE TRIGGER archive_areas AFTER UPDATE OF deleted_at OR DELETE ON areas FOR EACH ROW EXECUTE PROCEDURE archive_record();
CREATE TRIGGER archive_comments AFTER UPDATE OF deleted_at OR DELETE ON comments FOR EACH ROW EXECUTE PROCEDURE archive_record();
CREATE TRIGGER archive_iterations AFTER UPDATE OF deleted_at OR DELETE ON iterations FOR EACH ROW EXECUTE PROCEDURE archive_record();
CREATE TRIGGER archive_labels AFTER UPDATE OF deleted_at OR DELETE ON labels FOR EACH ROW EXECUTE PROCEDURE archive_record();
CREATE TRIGGER archive_space_templates AFTER UPDATE OF deleted_at OR DELETE ON space_templates FOR EACH ROW EXECUTE PROCEDURE archive_record();
CREATE TRIGGER archive_spaces AFTER UPDATE OF deleted_at OR DELETE ON spaces FOR EACH ROW EXECUTE PROCEDURE archive_record();
CREATE TRIGGER archive_work_item_link_types AFTER UPDATE OF deleted_at OR DELETE ON work_item_link_types FOR EACH ROW EXECUTE PROCEDURE archive_record();
CREATE TRIGGER archive_work_item_links AFTER UPDATE OF deleted_at OR DELETE ON work_item_links FOR EACH ROW EXECUTE PROCEDURE archive_record();
CREATE TRIGGER archive_work_item_types AFTER UPDATE OF deleted_at OR DELETE ON work_item_types FOR EACH ROW EXECUTE PROCEDURE archive_record();
CREATE TRIGGER archive_work_items AFTER UPDATE OF deleted_at OR DELETE ON work_items FOR EACH ROW EXECUTE PROCEDURE archive_record();

-- Archive all deleted records
DELETE FROM areas WHERE deleted_at IS NOT NULL;
DELETE FROM comments WHERE deleted_at IS NOT NULL;
DELETE FROM iterations WHERE deleted_at IS NOT NULL;
DELETE FROM labels WHERE deleted_at IS NOT NULL;
DELETE FROM space_templates WHERE deleted_at IS NOT NULL;
DELETE FROM spaces WHERE deleted_at IS NOT NULL;
DELETE FROM work_item_link_types WHERE deleted_at IS NOT NULL;
DELETE FROM work_item_links WHERE deleted_at IS NOT NULL;
DELETE FROM work_item_types WHERE deleted_at IS NOT NULL;
DELETE FROM work_items WHERE deleted_at IS NOT NULL;
56 changes: 56 additions & 0 deletions migration/sql-test-files/111-cascading-soft-delete-update.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,56 @@
SET id.area = '{{index . 0}}';
SET id.areaDeleted = '{{index . 1}}';
SET id.comment = '{{index . 2}}';
SET id.commentDeleted = '{{index . 3}}';
SET id.iter = '{{index . 4}}';
SET id.iterDeleted = '{{index . 5}}';
SET id.label = '{{index . 6}}';
SET id.labelDeleted = '{{index . 7}}';
SET id.space = '{{index . 8}}';
SET id.spaceDeleted = '{{index . 9}}';
SET id.spaceTemplate = '{{index . 10}}';
SET id.spaceTemplateDeleted = '{{index . 11}}';
SET id.workItem = '{{index . 12}}';
SET id.workItemDeleted = '{{index . 13}}';
SET id.workItemLink = '{{index . 14}}';
SET id.workItemLinkDeleted = '{{index . 15}}';
SET id.workItemLinkType = '{{index . 16}}';
SET id.workItemLinkTypeDeleted = '{{index . 17}}';
SET id.workItemType = '{{index . 18}}';
SET id.workItemTypeDeleted = '{{index . 19}}';

INSERT INTO space_templates (id,name,description, deleted_at) VALUES
(current_setting('id.spaceTemplate')::uuid, current_setting('id.spaceTemplate'), 'test template', NULL),
(current_setting('id.spaceTemplateDeleted')::uuid, current_setting('id.spaceTemplateDeleted'), 'test template', '2018-09-17 16:01');

INSERT INTO spaces (id,name,space_template_id, deleted_at) VALUES
(current_setting('id.space')::uuid, current_setting('id.space'), current_setting('id.spaceTemplate')::uuid, NULL),
(current_setting('id.spaceDeleted')::uuid, current_setting('id.spaceDeleted'), current_setting('id.spaceTemplate')::uuid, '2018-09-17 16:01');

INSERT INTO iterations (id, name, path, space_id, deleted_at) VALUES
(current_setting('id.iterRoot')::uuid, 'root iteration', replace(current_setting('id.iter'), '-', '_')::ltree, current_setting('id.space')::uuid, NULL),
(current_setting('id.iterDeleted')::uuid, 'deleted iteration', replace(current_setting('id.iterDeleted'), '-', '_')::ltree, current_setting('id.space')::uuid, '2018-09-17 16:01');

INSERT INTO areas (id, name, path, space_id, deleted_at) VALUES
(current_setting('id.area')::uuid, 'area', replace(current_setting('id.area'), '-', '_')::ltree, current_setting('id.space')::uuid, NULL),
(current_setting('id.areaDeleted')::uuid, 'area deleted', replace(current_setting('id.areaDeleted'), '-', '_')::ltree, current_setting('id.space')::uuid, '2018-09-17 16:01');

INSERT INTO labels (id, name, text_color, background_color, space_id, deleted_at) VALUES
(current_setting('id.label')::uuid, 'some label', '#ffffff', '#000000', current_setting('id.space')::uuid, NULL),
(current_setting('id.labelDeleted')::uuid, 'deleted label', '#000000', '#ffffff', current_setting('id.space')::uuid, '2018-09-17 16:01'),

INSERT INTO work_item_types (id, name, space_template_id, fields, description, icon, deleted_at) VALUES
(current_setting('id.workItemType')::uuid, 'WIT1', current_setting('id.spaceTemplate')::uuid, '{"system.title": {"Type": {"Kind": "string"}, "Label": "Title", "Required": true, "Description": "The title text of the work item"}}', 'Description for WIT1', 'fa fa-bookmark', NULL),
(current_setting('id.workItemTypeDeleted')::uuid, 'WIT2 Deleted', current_setting('id.spaceTemplate')::uuid, '{"system.title": {"Type": {"Kind": "string"}, "Label": "Title", "Required": true, "Description": "The title text of the work item"}}', 'Description for WIT2 Deleted', 'fa fa-bookmark', '2018-09-17 16:01');

INSERT INTO work_items (id, type, space_id, fields, deleted_at) VALUES
(current_setting('id.workItem')::uuid, current_setting('id.workItemType')::uuid, current_setting('id.space')::uuid, '{"system.title":"Work item 1"}'::json, NULL),
(current_setting('id.workItemDeleted')::uuid, current_setting('id.workItemType')::uuid, current_setting('id.space')::uuid, '{"system.title":"Work item 2 Deleted"}'::json, '2018-09-17 16:01');

INSERT INTO comments (id, parent_id, body, deleted_at) VALUES
(current_setting('id.comment')::uuid, current_setting('id.workItem')::uuid, 'a comment', NULL),
(current_setting('id.commentDeleted')::uuid, current_setting('id.workItem')::uuid, 'another comment', '2018-09-17 16:01');

INSERT INTO work_item_link_types (id, name, forward_name, reverse_name, topology, space_template_id, deleted_at) VALUES
(current_setting('id.workItemLinkType')::uuid, 'Bug blocker', 'blocks', 'blocked by', 'network', current_setting('id.spaceTemplate')::uuid, NULL),
(current_setting('id.workItemLinkTypeDeleted')::uuid, 'Dependency', 'depends on', 'is dependent on', 'dependency', current_setting('id.spaceTemplate')::uuid, '2018-09-17 16:01');
4 changes: 4 additions & 0 deletions migration/sql-test-files/111-soft-delete-space-template.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
SET id.spaceTemplate = '{{index . 0}}';

-- This should cause all entities that reference the space template directly or indirectly to be soft-deleted as well
UPDATE space_templates SET deleted_at = '2018-09-17 16:01' WHERE id = current_setting('id.spaceTemplate')::uuid;

0 comments on commit 78a0143

Please sign in to comment.