-
Notifications
You must be signed in to change notification settings - Fork 6
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
* blog views on stories * update specs * rename variables * wildcards for blog cleanup deletion * prevent action duplication, to adhere to unique key constraint * clean up old duplicate actions before old object deletion * cascade delete for actions-object fk * cascade delete on all fk constraints * add renamed migration
- Loading branch information
1 parent
33a55cf
commit 9a4458d
Showing
4 changed files
with
80 additions
and
3 deletions.
There are no files selected for viewing
29 changes: 29 additions & 0 deletions
29
docker/compose/postgres/model/07-add-cascade-delete-to-fk-constraints.psql
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,29 @@ | ||
SET search_path TO EVENTS; | ||
|
||
-- remove existing fk constraints and re-create them with cascade deletion | ||
|
||
-- Actions table | ||
ALTER TABLE actions | ||
DROP CONSTRAINT fk_object; | ||
ALTER TABLE actions | ||
DROP CONSTRAINT fk_action_type; | ||
ALTER TABLE actions | ||
DROP CONSTRAINT fk_session; | ||
|
||
ALTER TABLE actions | ||
ADD CONSTRAINT fk_object FOREIGN KEY (object_id) REFERENCES objects (id) ON DELETE CASCADE; | ||
ALTER TABLE actions | ||
ADD CONSTRAINT fk_action_type FOREIGN KEY (action_type_id) REFERENCES action_types (id) ON DELETE CASCADE; | ||
ALTER TABLE actions | ||
ADD CONSTRAINT fk_session FOREIGN KEY (session_id) REFERENCES sessions (id) ON DELETE CASCADE; | ||
|
||
-- History table | ||
ALTER TABLE history | ||
DROP CONSTRAINT fk_object; | ||
ALTER TABLE history | ||
DROP CONSTRAINT fk_action_type; | ||
|
||
ALTER TABLE history | ||
ADD CONSTRAINT fk_object FOREIGN KEY (object_id) REFERENCES objects (id) ON DELETE CASCADE; | ||
ALTER TABLE history | ||
ADD CONSTRAINT fk_action_type FOREIGN KEY (action_type_id) REFERENCES action_types (id) ON DELETE CASCADE; |
44 changes: 44 additions & 0 deletions
44
docker/compose/postgres/model/08-clean-up-blog-objects.psql
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,44 @@ | ||
SET search_path TO EVENTS; | ||
|
||
-- ensure an object for the '/stories' uri exists for all /blog uris | ||
|
||
INSERT INTO objects (uri) | ||
(SELECT DISTINCT REPLACE(uri, '/blog/', '/stories/') | ||
FROM objects) ON CONFLICT DO NOTHING; | ||
|
||
-- on actions/history linked to /blog/ objects, update the link to be to the /stories/ object | ||
-- do not update old actions where a user viewed old & new objects in the same session already. | ||
|
||
UPDATE actions | ||
SET object_id=new_object_id | ||
FROM | ||
(SELECT old_actions.id old_action_id, | ||
new_objects.id new_object_id | ||
FROM objects old_objects | ||
INNER JOIN objects new_objects ON new_objects.uri=REPLACE(old_objects.uri, '/blog/', '/stories/') | ||
INNER JOIN actions old_actions ON old_actions.object_id=old_objects.id | ||
LEFT JOIN actions duplicate_actions ON ( | ||
duplicate_actions.object_id=new_objects.id | ||
AND duplicate_actions.session_id=old_actions.session_id | ||
AND duplicate_actions.action_type_id=old_actions.action_type_id) | ||
WHERE old_objects.uri like '%/blog/%' | ||
AND new_objects.uri like '%/stories/%' | ||
AND duplicate_actions.id IS NULL) old_actions_new_objects | ||
WHERE id=old_action_id; | ||
|
||
UPDATE history | ||
SET object_id=new_id | ||
FROM | ||
(SELECT old.id old_id, | ||
new.id new_id | ||
FROM objects old | ||
INNER JOIN objects new ON new.uri=REPLACE(old.uri, '/blog/', '/stories/') | ||
WHERE old.uri like '%/blog/%' | ||
AND new.uri like '%/stories/%') old_new | ||
WHERE object_id=old_id; | ||
|
||
-- delete the /blog/ objects | ||
|
||
DELETE | ||
FROM objects | ||
WHERE uri like '%/blog/%'; |
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