Skip to content

Commit

Permalink
MBS-11312: Add table to store changes to edit notes
Browse files Browse the repository at this point in the history
While originally I was just planning to make changes
to the edit note table and nothing else, discussion with the team
suggested that it would be better to actually have a table
that stores the changes. This gives us several benefits:
1) we can easily check if an edit note has been deleted or edited
2) we can see who and when made the change
3) we can store the reason the change was made
4) we can see the original value (useful in case a malicious actor
gets access to an admin account somehow, and also useful
to find proof of misconduct if the editor posts an edit note,
then removes it (after it has been emailed to the intended insultee).

This table won't be replicated nor dumped
(other than in private dumps).
  • Loading branch information
reosarevok authored and mwiencek committed May 12, 2023
1 parent 247ed9e commit 4ddcb78
Show file tree
Hide file tree
Showing 17 changed files with 151 additions and 0 deletions.
10 changes: 10 additions & 0 deletions admin/sql/CreateFKConstraints.sql
Expand Up @@ -500,6 +500,16 @@ ALTER TABLE edit_note
FOREIGN KEY (edit)
REFERENCES edit(id);

ALTER TABLE edit_note_change
ADD CONSTRAINT edit_note_change_fk_edit_note
FOREIGN KEY (edit_note)
REFERENCES edit_note(id);

ALTER TABLE edit_note_change
ADD CONSTRAINT edit_note_change_fk_change_editor
FOREIGN KEY (change_editor)
REFERENCES editor(id);

ALTER TABLE edit_note_recipient
ADD CONSTRAINT edit_note_recipient_fk_recipient
FOREIGN KEY (recipient)
Expand Down
2 changes: 2 additions & 0 deletions admin/sql/CreateIndexes.sql
Expand Up @@ -170,6 +170,8 @@ CREATE INDEX edit_url_idx ON edit_url (url);
CREATE INDEX edit_note_idx_edit ON edit_note (edit);
CREATE INDEX edit_note_idx_editor ON edit_note (editor);

CREATE INDEX edit_note_change_idx_edit_note ON edit_note_change (edit_note);

CREATE INDEX edit_note_recipient_idx_recipient ON edit_note_recipient (recipient);

CREATE UNIQUE INDEX event_idx_gid ON event (gid);
Expand Down
1 change: 1 addition & 0 deletions admin/sql/CreatePrimaryKeys.sql
Expand Up @@ -54,6 +54,7 @@ ALTER TABLE edit_instrument ADD CONSTRAINT edit_instrument_pkey PRIMARY KEY (edi
ALTER TABLE edit_label ADD CONSTRAINT edit_label_pkey PRIMARY KEY (edit, label);
ALTER TABLE edit_mood ADD CONSTRAINT edit_mood_pkey PRIMARY KEY (edit, mood);
ALTER TABLE edit_note ADD CONSTRAINT edit_note_pkey PRIMARY KEY (id);
ALTER TABLE edit_note_change ADD CONSTRAINT edit_note_change_pkey PRIMARY KEY (id);
ALTER TABLE edit_note_recipient ADD CONSTRAINT edit_note_recipient_pkey PRIMARY KEY (recipient, edit_note);
ALTER TABLE edit_place ADD CONSTRAINT edit_place_pkey PRIMARY KEY (edit, place);
ALTER TABLE edit_recording ADD CONSTRAINT edit_recording_pkey PRIMARY KEY (edit, recording);
Expand Down
12 changes: 12 additions & 0 deletions admin/sql/CreateTables.sql
Expand Up @@ -575,6 +575,18 @@ CREATE TABLE edit_note
post_time TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);

CREATE TABLE edit_note_change
(
id SERIAL, -- PK
status edit_note_status,
edit_note INTEGER NOT NULL, -- references edit_note.id
change_editor INTEGER NOT NULL, -- references editor.id
change_time TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
old_note TEXT NOT NULL,
new_note TEXT NOT NULL,
reason TEXT NOT NULL DEFAULT ''
);

CREATE TABLE edit_note_recipient (
recipient INTEGER NOT NULL, -- PK, references editor.id
edit_note INTEGER NOT NULL -- PK, references edit_note.id
Expand Down
2 changes: 2 additions & 0 deletions admin/sql/CreateTypes.sql
Expand Up @@ -3,6 +3,8 @@ BEGIN;

CREATE TYPE cover_art_presence AS ENUM ('absent', 'present', 'darkened');

CREATE TYPE edit_note_status AS ENUM ('deleted', 'edited');

CREATE TYPE event_art_presence AS ENUM ('absent', 'present', 'darkened');

CREATE TYPE fluency AS ENUM (
Expand Down
2 changes: 2 additions & 0 deletions admin/sql/DropFKConstraints.sql
Expand Up @@ -98,6 +98,8 @@ ALTER TABLE edit_mood DROP CONSTRAINT IF EXISTS edit_mood_fk_edit;
ALTER TABLE edit_mood DROP CONSTRAINT IF EXISTS edit_mood_fk_mood;
ALTER TABLE edit_note DROP CONSTRAINT IF EXISTS edit_note_fk_editor;
ALTER TABLE edit_note DROP CONSTRAINT IF EXISTS edit_note_fk_edit;
ALTER TABLE edit_note_change DROP CONSTRAINT IF EXISTS edit_note_change_fk_edit_note;
ALTER TABLE edit_note_change DROP CONSTRAINT IF EXISTS edit_note_change_fk_change_editor;
ALTER TABLE edit_note_recipient DROP CONSTRAINT IF EXISTS edit_note_recipient_fk_recipient;
ALTER TABLE edit_note_recipient DROP CONSTRAINT IF EXISTS edit_note_recipient_fk_edit_note;
ALTER TABLE edit_place DROP CONSTRAINT IF EXISTS edit_place_fk_edit;
Expand Down
1 change: 1 addition & 0 deletions admin/sql/DropIndexes.sql
Expand Up @@ -87,6 +87,7 @@ DROP INDEX edit_instrument_idx;
DROP INDEX edit_label_idx;
DROP INDEX edit_label_idx_status;
DROP INDEX edit_mood_idx;
DROP INDEX edit_note_change_idx_edit_note;
DROP INDEX edit_note_idx_edit;
DROP INDEX edit_note_idx_editor;
DROP INDEX edit_note_recipient_idx_recipient;
Expand Down
1 change: 1 addition & 0 deletions admin/sql/DropPrimaryKeys.sql
Expand Up @@ -54,6 +54,7 @@ ALTER TABLE edit_instrument DROP CONSTRAINT IF EXISTS edit_instrument_pkey;
ALTER TABLE edit_label DROP CONSTRAINT IF EXISTS edit_label_pkey;
ALTER TABLE edit_mood DROP CONSTRAINT IF EXISTS edit_mood_pkey;
ALTER TABLE edit_note DROP CONSTRAINT IF EXISTS edit_note_pkey;
ALTER TABLE edit_note_change DROP CONSTRAINT IF EXISTS edit_note_change_pkey;
ALTER TABLE edit_note_recipient DROP CONSTRAINT IF EXISTS edit_note_recipient_pkey;
ALTER TABLE edit_place DROP CONSTRAINT IF EXISTS edit_place_pkey;
ALTER TABLE edit_recording DROP CONSTRAINT IF EXISTS edit_recording_pkey;
Expand Down
1 change: 1 addition & 0 deletions admin/sql/DropTables.sql
Expand Up @@ -58,6 +58,7 @@ DROP TABLE edit_instrument;
DROP TABLE edit_label;
DROP TABLE edit_mood;
DROP TABLE edit_note;
DROP TABLE edit_note_change;
DROP TABLE edit_note_recipient;
DROP TABLE edit_place;
DROP TABLE edit_recording;
Expand Down
1 change: 1 addition & 0 deletions admin/sql/DropTypes.sql
Expand Up @@ -2,6 +2,7 @@
\unset ON_ERROR_STOP

DROP TYPE IF EXISTS cover_art_presence;
DROP TYPE IF EXISTS edit_note_status;
DROP TYPE IF EXISTS event_art_presence;
DROP TYPE IF EXISTS fluency;
DROP TYPE IF EXISTS oauth_code_challenge_method;
Expand Down
1 change: 1 addition & 0 deletions admin/sql/SetSequences.sql
Expand Up @@ -28,6 +28,7 @@ SELECT setval('cdtoc_id_seq', COALESCE((SELECT MAX(id) FROM cdtoc), 0) + 1, FALS
SELECT setval('cdtoc_raw_id_seq', COALESCE((SELECT MAX(id) FROM cdtoc_raw), 0) + 1, FALSE);
SELECT setval('edit_id_seq', COALESCE((SELECT MAX(id) FROM edit), 0) + 1, FALSE);
SELECT setval('edit_note_id_seq', COALESCE((SELECT MAX(id) FROM edit_note), 0) + 1, FALSE);
SELECT setval('edit_note_change_id_seq', COALESCE((SELECT MAX(id) FROM edit_note_change), 0) + 1, FALSE);
SELECT setval('editor_id_seq', COALESCE((SELECT MAX(id) FROM editor), 0) + 1, FALSE);
SELECT setval('editor_preference_id_seq', COALESCE((SELECT MAX(id) FROM editor_preference), 0) + 1, FALSE);
SELECT setval('editor_subscribe_artist_id_seq', COALESCE((SELECT MAX(id) FROM editor_subscribe_artist), 0) + 1, FALSE);
Expand Down
1 change: 1 addition & 0 deletions admin/sql/TruncateTables.sql
Expand Up @@ -58,6 +58,7 @@ TRUNCATE TABLE edit_instrument RESTART IDENTITY CASCADE;
TRUNCATE TABLE edit_label RESTART IDENTITY CASCADE;
TRUNCATE TABLE edit_mood RESTART IDENTITY CASCADE;
TRUNCATE TABLE edit_note RESTART IDENTITY CASCADE;
TRUNCATE TABLE edit_note_change RESTART IDENTITY CASCADE;
TRUNCATE TABLE edit_note_recipient RESTART IDENTITY CASCADE;
TRUNCATE TABLE edit_place RESTART IDENTITY CASCADE;
TRUNCATE TABLE edit_recording RESTART IDENTITY CASCADE;
Expand Down
17 changes: 17 additions & 0 deletions admin/sql/updates/20211203-mbs-11312-standalone.sql
@@ -0,0 +1,17 @@
\set ON_ERROR_STOP 1

BEGIN;

-- Foreign keys

ALTER TABLE edit_note_change
ADD CONSTRAINT edit_note_change_fk_edit_note
FOREIGN KEY (edit_note)
REFERENCES edit_note(id);

ALTER TABLE edit_note_change
ADD CONSTRAINT edit_note_change_fk_change_editor
FOREIGN KEY (change_editor)
REFERENCES editor(id);

COMMIT;
36 changes: 36 additions & 0 deletions admin/sql/updates/20211203-mbs-11312.sql
@@ -0,0 +1,36 @@
\set ON_ERROR_STOP 1

BEGIN;

DO $$
BEGIN
PERFORM 1 FROM pg_type
WHERE typname = 'edit_note_status';

IF NOT FOUND THEN
CREATE TYPE edit_note_status AS ENUM ('deleted', 'edited');
END IF;
END
$$;

CREATE TABLE edit_note_change
(
id SERIAL, -- PK
status edit_note_status,
edit_note INTEGER NOT NULL, -- references edit_note.id
change_editor INTEGER NOT NULL, -- references editor.id
change_time TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
old_note TEXT NOT NULL,
new_note TEXT NOT NULL,
reason TEXT NOT NULL DEFAULT ''
);

-- Primary keys

ALTER TABLE edit_note_change ADD CONSTRAINT edit_note_change_pkey PRIMARY KEY (id);

-- Indexes

CREATE INDEX edit_note_change_idx_edit_note ON edit_note_change (edit_note);

COMMIT;
36 changes: 36 additions & 0 deletions admin/sql/updates/schema-change/28.all.sql
@@ -1,4 +1,5 @@
-- Generated by CompileSchemaScripts.pl from:
-- 20211203-mbs-11312.sql
-- 20220802-mbs-12497.sql
-- 20220927-mbs-12573.sql
-- 20221114-mbs-12704.sql
Expand All @@ -7,6 +8,41 @@
BEGIN;
SET search_path = musicbrainz, public;
SET LOCAL statement_timeout = 0;
--------------------------------------------------------------------------------
SELECT '20211203-mbs-11312.sql';


DO $$
BEGIN
PERFORM 1 FROM pg_type
WHERE typname = 'edit_note_status';

IF NOT FOUND THEN
CREATE TYPE edit_note_status AS ENUM ('deleted', 'edited');
END IF;
END
$$;

CREATE TABLE edit_note_change
(
id SERIAL, -- PK
status edit_note_status,
edit_note INTEGER NOT NULL, -- references edit_note.id
change_editor INTEGER NOT NULL, -- references editor.id
change_time TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
old_note TEXT NOT NULL,
new_note TEXT NOT NULL,
reason TEXT NOT NULL DEFAULT ''
);

-- Primary keys

ALTER TABLE edit_note_change ADD CONSTRAINT edit_note_change_pkey PRIMARY KEY (id);

-- Indexes

CREATE INDEX edit_note_change_idx_edit_note ON edit_note_change (edit_note);

--------------------------------------------------------------------------------
SELECT '20220802-mbs-12497.sql';

Expand Down
23 changes: 23 additions & 0 deletions admin/sql/updates/schema-change/28.master_or_standalone.sql
@@ -0,0 +1,23 @@
-- Generated by CompileSchemaScripts.pl from:
-- 20211203-mbs-11312-standalone.sql
\set ON_ERROR_STOP 1
BEGIN;
SET search_path = musicbrainz, public;
SET LOCAL statement_timeout = 0;
--------------------------------------------------------------------------------
SELECT '20211203-mbs-11312-standalone.sql';


-- Foreign keys

ALTER TABLE edit_note_change
ADD CONSTRAINT edit_note_change_fk_edit_note
FOREIGN KEY (edit_note)
REFERENCES edit_note(id);

ALTER TABLE edit_note_change
ADD CONSTRAINT edit_note_change_fk_change_editor
FOREIGN KEY (change_editor)
REFERENCES editor(id);

COMMIT;
4 changes: 4 additions & 0 deletions upgrade.json
Expand Up @@ -206,13 +206,17 @@
},
"28": {
"all": [
"20211203-mbs-11312.sql",
"20220802-mbs-12497.sql",
"20220927-mbs-12573.sql",
"20221114-mbs-12704.sql",
"20230320-mbs-12800.sql"
],
"master_only": [
"20230423-nix-pending-keys-insertion.sql"
],
"master_or_standalone": [
"20211203-mbs-11312-standalone.sql"
]
}
}

0 comments on commit 4ddcb78

Please sign in to comment.