This repository has been archived by the owner on Mar 11, 2021. It is now read-only.
-
Notifications
You must be signed in to change notification settings - Fork 86
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
6 changed files
with
264 additions
and
2 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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
56
migration/sql-test-files/111-cascading-soft-delete-update.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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'); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; |