From 7ae0b2fdcec4e9cb717dd5655c0086e1a8e7545f Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Luk=C3=A1=C5=A1=20Lalinsk=C3=BD?= Date: Mon, 22 May 2023 16:37:12 +0200 Subject: [PATCH 1/2] Update SQL files --- mbslave/sql/CreateFKConstraints.sql | 50 +---- mbslave/sql/CreateFunctions.sql | 43 ++-- mbslave/sql/CreateIndexes.sql | 4 + mbslave/sql/CreatePrimaryKeys.sql | 6 +- mbslave/sql/CreateTables.sql | 45 ++--- mbslave/sql/CreateTriggers.sql | 3 - mbslave/sql/CreateTypes.sql | 2 + mbslave/sql/DropFKConstraints.sql | 9 +- mbslave/sql/DropFunctions.sql | 1 - mbslave/sql/DropIndexes.sql | 2 + mbslave/sql/DropPrimaryKeys.sql | 6 +- mbslave/sql/DropTables.sql | 6 +- mbslave/sql/DropTriggers.sql | 1 - mbslave/sql/DropTypes.sql | 1 + mbslave/sql/InsertTestData.sql | 34 ++-- mbslave/sql/SetSequences.sql | 1 + mbslave/sql/TruncateTables.sql | 6 +- mbslave/sql/dbmirror2/MasterSetup.sql | 13 -- mbslave/sql/dbmirror2/README | 2 +- .../20130309-migrate-transclusion-table.pl | 5 +- .../sql/updates/20130313-bcrypt-passwords.pl | 3 +- .../20130322-init-bundled-replication.pl | 16 -- .../20130724-refresh-release_meta-asin.sql | 2 +- .../20130906-materialise-recording-lengths.pl | 3 +- .../updates/20211203-mbs-11312-standalone.sql | 17 ++ mbslave/sql/updates/20211203-mbs-11312.sql | 36 ++++ .../sql/updates/20220207-mbs-12224-mirror.sql | 162 --------------- .../updates/20220207-mbs-12224-standalone.sql | 162 +++++++++++++++ mbslave/sql/updates/20220720-mbs-12508.sh | 155 +++++++++++++++ mbslave/sql/updates/20220802-mbs-12497.sql | 28 +++ mbslave/sql/updates/20220927-mbs-12573.sql | 7 + mbslave/sql/updates/20221114-mbs-12704.sql | 14 ++ mbslave/sql/updates/20230320-mbs-12800.sql | 97 +++++++++ .../20230423-nix-pending-keys-insertion.sql | 130 ++++++++++++ .../{20.mirror.sql => 20.all.sql} | 0 ...alone.sql => 20.master_and_standalone.sql} | 0 .../{21.mirror.sql => 21.all.sql} | 0 ...alone.sql => 21.master_and_standalone.sql} | 0 .../{22.mirror.sql => 22.all.sql} | 0 ...alone.sql => 22.master_and_standalone.sql} | 0 .../{23.mirror.sql => 23.all.sql} | 0 ...3.extensions.sql => 23.all_extensions.sql} | 0 ...alone.sql => 23.master_and_standalone.sql} | 0 .../{24.mirror.sql => 24.all.sql} | 0 ...alone.sql => 24.master_and_standalone.sql} | 0 .../{25.mirror.sql => 25.all.sql} | 0 ...alone.sql => 25.master_and_standalone.sql} | 0 .../{26.mirror.sql => 26.all.sql} | 0 ...alone.sql => 26.master_and_standalone.sql} | 0 .../{27.mirror.sql => 27.all.sql} | 162 --------------- ...alone.sql => 27.master_and_standalone.sql} | 162 +++++++++++++++ mbslave/sql/updates/schema-change/28.all.sql | 188 ++++++++++++++++++ .../28.master_and_standalone.sql | 23 +++ .../updates/schema-change/28.master_only.sql | 136 +++++++++++++ scripts/update_sql.sh | 2 +- 55 files changed, 1254 insertions(+), 491 deletions(-) delete mode 100755 mbslave/sql/updates/20130322-init-bundled-replication.pl create mode 100644 mbslave/sql/updates/20211203-mbs-11312-standalone.sql create mode 100644 mbslave/sql/updates/20211203-mbs-11312.sql create mode 100755 mbslave/sql/updates/20220720-mbs-12508.sh create mode 100644 mbslave/sql/updates/20220802-mbs-12497.sql create mode 100644 mbslave/sql/updates/20220927-mbs-12573.sql create mode 100644 mbslave/sql/updates/20221114-mbs-12704.sql create mode 100644 mbslave/sql/updates/20230320-mbs-12800.sql create mode 100644 mbslave/sql/updates/20230423-nix-pending-keys-insertion.sql rename mbslave/sql/updates/schema-change/{20.mirror.sql => 20.all.sql} (100%) rename mbslave/sql/updates/schema-change/{20.standalone.sql => 20.master_and_standalone.sql} (100%) rename mbslave/sql/updates/schema-change/{21.mirror.sql => 21.all.sql} (100%) rename mbslave/sql/updates/schema-change/{21.standalone.sql => 21.master_and_standalone.sql} (100%) rename mbslave/sql/updates/schema-change/{22.mirror.sql => 22.all.sql} (100%) rename mbslave/sql/updates/schema-change/{22.standalone.sql => 22.master_and_standalone.sql} (100%) rename mbslave/sql/updates/schema-change/{23.mirror.sql => 23.all.sql} (100%) rename mbslave/sql/updates/schema-change/{23.extensions.sql => 23.all_extensions.sql} (100%) rename mbslave/sql/updates/schema-change/{23.standalone.sql => 23.master_and_standalone.sql} (100%) rename mbslave/sql/updates/schema-change/{24.mirror.sql => 24.all.sql} (100%) rename mbslave/sql/updates/schema-change/{24.standalone.sql => 24.master_and_standalone.sql} (100%) rename mbslave/sql/updates/schema-change/{25.mirror.sql => 25.all.sql} (100%) rename mbslave/sql/updates/schema-change/{25.standalone.sql => 25.master_and_standalone.sql} (100%) rename mbslave/sql/updates/schema-change/{26.mirror.sql => 26.all.sql} (100%) rename mbslave/sql/updates/schema-change/{26.standalone.sql => 26.master_and_standalone.sql} (100%) rename mbslave/sql/updates/schema-change/{27.mirror.sql => 27.all.sql} (94%) rename mbslave/sql/updates/schema-change/{27.standalone.sql => 27.master_and_standalone.sql} (95%) create mode 100644 mbslave/sql/updates/schema-change/28.all.sql create mode 100644 mbslave/sql/updates/schema-change/28.master_and_standalone.sql create mode 100644 mbslave/sql/updates/schema-change/28.master_only.sql diff --git a/mbslave/sql/CreateFKConstraints.sql b/mbslave/sql/CreateFKConstraints.sql index 33f3be0..0acd3f2 100644 --- a/mbslave/sql/CreateFKConstraints.sql +++ b/mbslave/sql/CreateFKConstraints.sql @@ -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) @@ -877,46 +887,6 @@ ALTER TABLE editor_subscribe_series_deleted FOREIGN KEY (deleted_by) REFERENCES edit(id); -ALTER TABLE editor_watch_artist - ADD CONSTRAINT editor_watch_artist_fk_artist - FOREIGN KEY (artist) - REFERENCES artist(id) - ON DELETE CASCADE; - -ALTER TABLE editor_watch_artist - ADD CONSTRAINT editor_watch_artist_fk_editor - FOREIGN KEY (editor) - REFERENCES editor(id) - ON DELETE CASCADE; - -ALTER TABLE editor_watch_preferences - ADD CONSTRAINT editor_watch_preferences_fk_editor - FOREIGN KEY (editor) - REFERENCES editor(id) - ON DELETE CASCADE; - -ALTER TABLE editor_watch_release_group_type - ADD CONSTRAINT editor_watch_release_group_type_fk_editor - FOREIGN KEY (editor) - REFERENCES editor(id) - ON DELETE CASCADE; - -ALTER TABLE editor_watch_release_group_type - ADD CONSTRAINT editor_watch_release_group_type_fk_release_group_type - FOREIGN KEY (release_group_type) - REFERENCES release_group_primary_type(id); - -ALTER TABLE editor_watch_release_status - ADD CONSTRAINT editor_watch_release_status_fk_editor - FOREIGN KEY (editor) - REFERENCES editor(id) - ON DELETE CASCADE; - -ALTER TABLE editor_watch_release_status - ADD CONSTRAINT editor_watch_release_status_fk_release_status - FOREIGN KEY (release_status) - REFERENCES release_status(id); - ALTER TABLE event ADD CONSTRAINT event_fk_type FOREIGN KEY (type) diff --git a/mbslave/sql/CreateFunctions.sql b/mbslave/sql/CreateFunctions.sql index 89696ef..53cc407 100644 --- a/mbslave/sql/CreateFunctions.sql +++ b/mbslave/sql/CreateFunctions.sql @@ -101,13 +101,12 @@ DECLARE ref_count integer; BEGIN -- decrement ref_count for the old name, - -- or delete it if ref_count would drop to 0 + -- or prepare it for deletion if ref_count would drop to 0 EXECUTE 'SELECT ref_count FROM ' || tbl || ' WHERE id = ' || row_id || ' FOR UPDATE' INTO ref_count; IF ref_count <= val THEN - EXECUTE 'DELETE FROM ' || tbl || ' WHERE id = ' || row_id; - ELSE - EXECUTE 'UPDATE ' || tbl || ' SET ref_count = ref_count - ' || val || ' WHERE id = ' || row_id; + EXECUTE 'INSERT INTO unreferenced_row_log (table_name, row_id) VALUES ($1, $2)' USING tbl, row_id; END IF; + EXECUTE 'UPDATE ' || tbl || ' SET ref_count = ref_count - ' || val || ' WHERE id = ' || row_id; RETURN; END; $$ LANGUAGE 'plpgsql'; @@ -204,21 +203,6 @@ $$ LANGUAGE 'plpgsql'; -- editor triggers ----------------------------------------------------------------------- -CREATE OR REPLACE FUNCTION a_ins_editor() RETURNS trigger AS $$ -BEGIN - -- add a new entry to the editor_watch_preference table - INSERT INTO editor_watch_preferences (editor) VALUES (NEW.id); - - -- by default watch for new official albums - INSERT INTO editor_watch_release_group_type (editor, release_group_type) - VALUES (NEW.id, 2); - INSERT INTO editor_watch_release_status (editor, release_status) - VALUES (NEW.id, 1); - - RETURN NULL; -END; -$$ LANGUAGE 'plpgsql'; - CREATE OR REPLACE FUNCTION check_editor_name() RETURNS trigger AS $$ BEGIN IF (SELECT 1 FROM old_editor_name WHERE lower(name) = lower(NEW.name)) @@ -495,6 +479,19 @@ BEGIN PERFORM dec_ref_count('artist_credit', OLD.artist_credit, 1); PERFORM inc_ref_count('artist_credit', NEW.artist_credit, 1); END IF; + IF ( + NEW.status IS DISTINCT FROM OLD.status AND + (NEW.status = 6 OR OLD.status = 6) + ) THEN + PERFORM set_release_first_release_date(NEW.id); + + -- avoid executing it twice as this will be executed a few lines below if RG changes + IF NEW.release_group = OLD.release_group THEN + PERFORM set_release_group_first_release_date(NEW.release_group); + END IF; + + PERFORM set_releases_recordings_first_release_dates(ARRAY[NEW.id]); + END IF; IF NEW.release_group != OLD.release_group THEN -- release group is changed, decrement release_count in the original RG, increment in the new one UPDATE release_group_meta SET release_count = release_count - 1 WHERE id = OLD.release_group; @@ -1082,7 +1079,13 @@ BEGIN SELECT release, date_year, date_month, date_day FROM release_unknown_country ) all_dates WHERE ' || condition || - ' ORDER BY release, year NULLS LAST, month NULLS LAST, day NULLS LAST'; + ' AND NOT EXISTS ( + SELECT TRUE + FROM release + WHERE release.id = all_dates.release + AND status = 6 + ) + ORDER BY release, year NULLS LAST, month NULLS LAST, day NULLS LAST'; END; $$ LANGUAGE 'plpgsql' STRICT; diff --git a/mbslave/sql/CreateIndexes.sql b/mbslave/sql/CreateIndexes.sql index c242c6a..d1bf178 100644 --- a/mbslave/sql/CreateIndexes.sql +++ b/mbslave/sql/CreateIndexes.sql @@ -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); @@ -671,6 +673,8 @@ CREATE INDEX track_raw_idx_release ON track_raw (release); CREATE INDEX medium_idx_track_count ON medium (track_count); CREATE INDEX medium_index_idx ON medium_index USING gist (toc); +CREATE INDEX unreferenced_row_log_idx_inserted ON unreferenced_row_log USING BRIN (inserted); + CREATE UNIQUE INDEX url_idx_gid ON url (gid); CREATE UNIQUE INDEX url_idx_url ON url (url); diff --git a/mbslave/sql/CreatePrimaryKeys.sql b/mbslave/sql/CreatePrimaryKeys.sql index 1242b32..7d7988f 100644 --- a/mbslave/sql/CreatePrimaryKeys.sql +++ b/mbslave/sql/CreatePrimaryKeys.sql @@ -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); @@ -90,10 +91,6 @@ ALTER TABLE editor_subscribe_label ADD CONSTRAINT editor_subscribe_label_pkey PR ALTER TABLE editor_subscribe_label_deleted ADD CONSTRAINT editor_subscribe_label_deleted_pkey PRIMARY KEY (editor, gid); ALTER TABLE editor_subscribe_series ADD CONSTRAINT editor_subscribe_series_pkey PRIMARY KEY (id); ALTER TABLE editor_subscribe_series_deleted ADD CONSTRAINT editor_subscribe_series_deleted_pkey PRIMARY KEY (editor, gid); -ALTER TABLE editor_watch_artist ADD CONSTRAINT editor_watch_artist_pkey PRIMARY KEY (artist, editor); -ALTER TABLE editor_watch_preferences ADD CONSTRAINT editor_watch_preferences_pkey PRIMARY KEY (editor); -ALTER TABLE editor_watch_release_group_type ADD CONSTRAINT editor_watch_release_group_type_pkey PRIMARY KEY (editor, release_group_type); -ALTER TABLE editor_watch_release_status ADD CONSTRAINT editor_watch_release_status_pkey PRIMARY KEY (editor, release_status); ALTER TABLE event ADD CONSTRAINT event_pkey PRIMARY KEY (id); ALTER TABLE event_alias ADD CONSTRAINT event_alias_pkey PRIMARY KEY (id); ALTER TABLE event_alias_type ADD CONSTRAINT event_alias_type_pkey PRIMARY KEY (id); @@ -350,6 +347,7 @@ ALTER TABLE tag_relation ADD CONSTRAINT tag_relation_pkey PRIMARY KEY (tag1, tag ALTER TABLE track ADD CONSTRAINT track_pkey PRIMARY KEY (id); ALTER TABLE track_gid_redirect ADD CONSTRAINT track_gid_redirect_pkey PRIMARY KEY (gid); ALTER TABLE track_raw ADD CONSTRAINT track_raw_pkey PRIMARY KEY (id); +ALTER TABLE unreferenced_row_log ADD CONSTRAINT unreferenced_row_log_pkey PRIMARY KEY (table_name, row_id); ALTER TABLE url ADD CONSTRAINT url_pkey PRIMARY KEY (id); ALTER TABLE url_gid_redirect ADD CONSTRAINT url_gid_redirect_pkey PRIMARY KEY (gid); ALTER TABLE vote ADD CONSTRAINT vote_pkey PRIMARY KEY (id); diff --git a/mbslave/sql/CreateTables.sql b/mbslave/sql/CreateTables.sql index 30e3f70..c9d24e0 100644 --- a/mbslave/sql/CreateTables.sql +++ b/mbslave/sql/CreateTables.sql @@ -524,7 +524,6 @@ CREATE TABLE cdtoc ( -- replicate track_count INTEGER NOT NULL, leadout_offset INTEGER NOT NULL, track_offset INTEGER[] NOT NULL, - degraded BOOLEAN NOT NULL DEFAULT FALSE, created TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); @@ -576,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 @@ -2881,32 +2892,6 @@ CREATE TABLE editor_oauth_token ) ); -CREATE TABLE editor_watch_preferences -( - editor INTEGER NOT NULL, -- PK, references editor.id CASCADE - notify_via_email BOOLEAN NOT NULL DEFAULT TRUE, - notification_timeframe INTERVAL NOT NULL DEFAULT '1 week', - last_checked TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() -); - -CREATE TABLE editor_watch_artist -( - artist INTEGER NOT NULL, -- PK, references artist.id CASCADE - editor INTEGER NOT NULL -- PK, references editor.id CASCADE -); - -CREATE TABLE editor_watch_release_group_type -( - editor INTEGER NOT NULL, -- PK, references editor.id CASCADE - release_group_type INTEGER NOT NULL -- PK, references release_group_primary_type.id -); - -CREATE TABLE editor_watch_release_status -( - editor INTEGER NOT NULL, -- PK, references editor.id CASCADE - release_status INTEGER NOT NULL -- PK, references release_status.id -); - CREATE TABLE medium ( -- replicate (verbose) id SERIAL, release INTEGER NOT NULL, -- references release.id @@ -3890,6 +3875,12 @@ CREATE TABLE medium_index ( -- replicate toc CUBE ); +CREATE TABLE unreferenced_row_log ( + table_name VARCHAR NOT NULL, -- PK + row_id INTEGER NOT NULL, -- PK + inserted TIMESTAMP WITH TIME ZONE DEFAULT NOW() +); + CREATE TABLE url ( -- replicate id SERIAL, gid UUID NOT NULL, diff --git a/mbslave/sql/CreateTriggers.sql b/mbslave/sql/CreateTriggers.sql index 7bc0cb8..148c7f8 100644 --- a/mbslave/sql/CreateTriggers.sql +++ b/mbslave/sql/CreateTriggers.sql @@ -64,9 +64,6 @@ CREATE TRIGGER b_upd_artist_tag BEFORE UPDATE ON artist_tag CREATE TRIGGER b_upd_editor BEFORE UPDATE ON editor FOR EACH ROW EXECUTE PROCEDURE b_upd_last_updated_table(); -CREATE TRIGGER a_ins_editor AFTER INSERT ON editor - FOR EACH ROW EXECUTE PROCEDURE a_ins_editor(); - CREATE TRIGGER check_editor_name BEFORE UPDATE OR INSERT ON editor FOR EACH ROW EXECUTE PROCEDURE check_editor_name(); diff --git a/mbslave/sql/CreateTypes.sql b/mbslave/sql/CreateTypes.sql index 2f1d9f3..0017064 100644 --- a/mbslave/sql/CreateTypes.sql +++ b/mbslave/sql/CreateTypes.sql @@ -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 ( diff --git a/mbslave/sql/DropFKConstraints.sql b/mbslave/sql/DropFKConstraints.sql index 6106915..ba59b6c 100644 --- a/mbslave/sql/DropFKConstraints.sql +++ b/mbslave/sql/DropFKConstraints.sql @@ -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; @@ -172,13 +174,6 @@ ALTER TABLE editor_subscribe_series DROP CONSTRAINT IF EXISTS editor_subscribe_s ALTER TABLE editor_subscribe_series_deleted DROP CONSTRAINT IF EXISTS editor_subscribe_series_deleted_fk_editor; ALTER TABLE editor_subscribe_series_deleted DROP CONSTRAINT IF EXISTS editor_subscribe_series_deleted_fk_gid; ALTER TABLE editor_subscribe_series_deleted DROP CONSTRAINT IF EXISTS editor_subscribe_series_deleted_fk_deleted_by; -ALTER TABLE editor_watch_artist DROP CONSTRAINT IF EXISTS editor_watch_artist_fk_artist; -ALTER TABLE editor_watch_artist DROP CONSTRAINT IF EXISTS editor_watch_artist_fk_editor; -ALTER TABLE editor_watch_preferences DROP CONSTRAINT IF EXISTS editor_watch_preferences_fk_editor; -ALTER TABLE editor_watch_release_group_type DROP CONSTRAINT IF EXISTS editor_watch_release_group_type_fk_editor; -ALTER TABLE editor_watch_release_group_type DROP CONSTRAINT IF EXISTS editor_watch_release_group_type_fk_release_group_type; -ALTER TABLE editor_watch_release_status DROP CONSTRAINT IF EXISTS editor_watch_release_status_fk_editor; -ALTER TABLE editor_watch_release_status DROP CONSTRAINT IF EXISTS editor_watch_release_status_fk_release_status; ALTER TABLE event DROP CONSTRAINT IF EXISTS event_fk_type; ALTER TABLE event_alias DROP CONSTRAINT IF EXISTS event_alias_fk_event; ALTER TABLE event_alias DROP CONSTRAINT IF EXISTS event_alias_fk_type; diff --git a/mbslave/sql/DropFunctions.sql b/mbslave/sql/DropFunctions.sql index ad6d583..e37ad16 100644 --- a/mbslave/sql/DropFunctions.sql +++ b/mbslave/sql/DropFunctions.sql @@ -17,7 +17,6 @@ DROP FUNCTION a_ins_alternative_medium_track(); DROP FUNCTION a_ins_alternative_release_or_track(); DROP FUNCTION a_ins_artist(); DROP FUNCTION a_ins_edit_note(); -DROP FUNCTION a_ins_editor(); DROP FUNCTION a_ins_event(); DROP FUNCTION a_ins_instrument(); DROP FUNCTION a_ins_l_area_area_mirror(); diff --git a/mbslave/sql/DropIndexes.sql b/mbslave/sql/DropIndexes.sql index e73d78f..4e83c1e 100644 --- a/mbslave/sql/DropIndexes.sql +++ b/mbslave/sql/DropIndexes.sql @@ -84,6 +84,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; @@ -506,6 +507,7 @@ DROP INDEX track_idx_artist_credit; DROP INDEX track_idx_gid; DROP INDEX track_idx_recording; DROP INDEX track_raw_idx_release; +DROP INDEX unreferenced_row_log_idx_inserted; DROP INDEX url_gid_redirect_idx_new_id; DROP INDEX url_idx_gid; DROP INDEX url_idx_url; diff --git a/mbslave/sql/DropPrimaryKeys.sql b/mbslave/sql/DropPrimaryKeys.sql index 48bad50..da41d8b 100644 --- a/mbslave/sql/DropPrimaryKeys.sql +++ b/mbslave/sql/DropPrimaryKeys.sql @@ -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; @@ -90,10 +91,6 @@ ALTER TABLE editor_subscribe_label DROP CONSTRAINT IF EXISTS editor_subscribe_la ALTER TABLE editor_subscribe_label_deleted DROP CONSTRAINT IF EXISTS editor_subscribe_label_deleted_pkey; ALTER TABLE editor_subscribe_series DROP CONSTRAINT IF EXISTS editor_subscribe_series_pkey; ALTER TABLE editor_subscribe_series_deleted DROP CONSTRAINT IF EXISTS editor_subscribe_series_deleted_pkey; -ALTER TABLE editor_watch_artist DROP CONSTRAINT IF EXISTS editor_watch_artist_pkey; -ALTER TABLE editor_watch_preferences DROP CONSTRAINT IF EXISTS editor_watch_preferences_pkey; -ALTER TABLE editor_watch_release_group_type DROP CONSTRAINT IF EXISTS editor_watch_release_group_type_pkey; -ALTER TABLE editor_watch_release_status DROP CONSTRAINT IF EXISTS editor_watch_release_status_pkey; ALTER TABLE event DROP CONSTRAINT IF EXISTS event_pkey; ALTER TABLE event_alias DROP CONSTRAINT IF EXISTS event_alias_pkey; ALTER TABLE event_alias_type DROP CONSTRAINT IF EXISTS event_alias_type_pkey; @@ -350,6 +347,7 @@ ALTER TABLE tag_relation DROP CONSTRAINT IF EXISTS tag_relation_pkey; ALTER TABLE track DROP CONSTRAINT IF EXISTS track_pkey; ALTER TABLE track_gid_redirect DROP CONSTRAINT IF EXISTS track_gid_redirect_pkey; ALTER TABLE track_raw DROP CONSTRAINT IF EXISTS track_raw_pkey; +ALTER TABLE unreferenced_row_log DROP CONSTRAINT IF EXISTS unreferenced_row_log_pkey; ALTER TABLE url DROP CONSTRAINT IF EXISTS url_pkey; ALTER TABLE url_gid_redirect DROP CONSTRAINT IF EXISTS url_gid_redirect_pkey; ALTER TABLE vote DROP CONSTRAINT IF EXISTS vote_pkey; diff --git a/mbslave/sql/DropTables.sql b/mbslave/sql/DropTables.sql index af0ec88..a5f2617 100644 --- a/mbslave/sql/DropTables.sql +++ b/mbslave/sql/DropTables.sql @@ -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; @@ -94,10 +95,6 @@ DROP TABLE editor_subscribe_label; DROP TABLE editor_subscribe_label_deleted; DROP TABLE editor_subscribe_series; DROP TABLE editor_subscribe_series_deleted; -DROP TABLE editor_watch_artist; -DROP TABLE editor_watch_preferences; -DROP TABLE editor_watch_release_group_type; -DROP TABLE editor_watch_release_status; DROP TABLE event; DROP TABLE event_alias; DROP TABLE event_alias_type; @@ -355,6 +352,7 @@ DROP TABLE tag_relation; DROP TABLE track; DROP TABLE track_gid_redirect; DROP TABLE track_raw; +DROP TABLE unreferenced_row_log; DROP TABLE url; DROP TABLE url_gid_redirect; DROP TABLE vote; diff --git a/mbslave/sql/DropTriggers.sql b/mbslave/sql/DropTriggers.sql index b781c53..17e54e9 100644 --- a/mbslave/sql/DropTriggers.sql +++ b/mbslave/sql/DropTriggers.sql @@ -22,7 +22,6 @@ DROP TRIGGER IF EXISTS restore_collection_sub_on_public ON editor_collection; DROP TRIGGER IF EXISTS search_hint ON artist_alias; DROP TRIGGER IF EXISTS b_upd_artist_tag ON artist_tag; DROP TRIGGER IF EXISTS b_upd_editor ON editor; -DROP TRIGGER IF EXISTS a_ins_editor ON editor; DROP TRIGGER IF EXISTS check_editor_name ON editor; DROP TRIGGER IF EXISTS a_ins_event ON event; DROP TRIGGER IF EXISTS b_upd_event ON event; diff --git a/mbslave/sql/DropTypes.sql b/mbslave/sql/DropTypes.sql index 6ae9a9a..b4c83ae 100644 --- a/mbslave/sql/DropTypes.sql +++ b/mbslave/sql/DropTypes.sql @@ -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; diff --git a/mbslave/sql/InsertTestData.sql b/mbslave/sql/InsertTestData.sql index 4938e39..9927e26 100644 --- a/mbslave/sql/InsertTestData.sql +++ b/mbslave/sql/InsertTestData.sql @@ -48,8 +48,8 @@ INSERT INTO artist_credit_name (artist_credit, position, artist, name) VALUES (2 INSERT INTO recording (id, gid, name, artist_credit, length) VALUES (1, '123c079d-374e-4436-9448-da92dedef3ce', 'Dancing Queen', 2, 123456); -INSERT INTO release_group (id, gid, name, artist_credit, type) VALUES - (1, '234c079d-374e-4436-9448-da92dedef3ce', 'Arrival', 2, 1); +INSERT INTO release_group (id, gid, name, artist_credit, type, last_updated) VALUES + (1, '234c079d-374e-4436-9448-da92dedef3ce', 'Arrival', 2, 1, '2003-03-03'); -- Test multiple release groups on a page INSERT INTO artist_credit (id, name, artist_count, gid) VALUES (4, 'Test Artist', 1, '261f02c2-75a6-313f-9dd8-1716f73f3ce8'); @@ -61,12 +61,12 @@ INSERT INTO release_group (id, gid, name, artist_credit, type) VALUES INSERT INTO release_group (id, gid, name, artist_credit, type) VALUES (4, '7348f3a0-454e-11de-8a39-0800200c9a66', 'Test RG 2', 4, 1); -INSERT INTO release_group_alias (id, name, sort_name, release_group, edits_pending) - VALUES (1, 'Test RG 1 Alias 1', 'Test RG 1 Alias Sort Name 1', 3, 0), - (2, 'Test RG 1 Alias 2', 'Test RG 1 Alias Sort Name 2', 3, 0); +INSERT INTO release_group_alias (id, name, sort_name, release_group, type, edits_pending) + VALUES (1, 'Test RG 1 Alias 1', 'Test RG 1 Alias Sort Name 1', 3, 1, 0), + (2, 'Test RG 1 Alias 2', 'Test RG 1 Alias Sort Name 2', 3, 2, 0); -INSERT INTO work (id, gid, name, type) VALUES - (1, '745c079d-374e-4436-9448-da92dedef3ce', 'Dancing Queen', 1); +INSERT INTO work (id, gid, name, type, last_updated) VALUES + (1, '745c079d-374e-4436-9448-da92dedef3ce', 'Dancing Queen', 1, '1999-01-02 12:00'); INSERT INTO iswc (work, iswc) VALUES (1, 'T-000.000.001-0'); -- Special Labels @@ -75,9 +75,11 @@ INSERT INTO label (id, gid, name, type) VALUES INSERT INTO label (id, gid, name, type, area, label_code, begin_date_year, begin_date_month, begin_date_day, - end_date_year, end_date_month, end_date_day, comment) + end_date_year, end_date_month, end_date_day, comment, + last_updated) VALUES (2, '46f0f4cd-8aab-4b33-b698-f459faf64190', 'Warp Records', 4, 221, 2070, - 1989, 02, 03, 2008, 05, 19, 'Sheffield based electronica label'); + 1989, 02, 03, 2008, 05, 19, 'Sheffield based electronica label', + '2014-01-12 18:00:27.843631-06'); -- recording contract relationships for Warp Records INSERT INTO link (attribute_count, begin_date_day, begin_date_month, begin_date_year, created, end_date_day, end_date_month, end_date_year, ended, id, link_type) VALUES @@ -140,11 +142,11 @@ INSERT INTO artist_credit_name (artist_credit, position, artist, name) VALUES (3 INSERT INTO release_group (id, gid, name, artist_credit, type) VALUES (2, '7c3218d7-75e0-4e8c-971f-f097b6c308c5', 'Aerial', 3, 1); -INSERT INTO release (id, gid, name, artist_credit, release_group, status, barcode) VALUES (2, 'f205627f-b70a-409d-adbe-66289b614e80', 'Aerial', 3, 2, 1, '0094634396028'); +INSERT INTO release (id, gid, name, artist_credit, release_group, status, barcode, last_updated) VALUES (2, 'f205627f-b70a-409d-adbe-66289b614e80', 'Aerial', 3, 2, 1, '0094634396028', '2020-02-20'); INSERT INTO release_country (release, country, date_year, date_month, date_day) VALUES (2, 221, 2005, 11, 7); -INSERT INTO release_alias (id, name, sort_name, release, edits_pending) - VALUES (1, 'Ærial', 'Ærial', 2, 0); +INSERT INTO release_alias (id, name, sort_name, release, type, edits_pending) + VALUES (1, 'Ærial', 'Ærial', 2, 1, 0); INSERT INTO release (id, gid, name, artist_credit, release_group, status, barcode) VALUES (3, '9b3d9383-3d2a-417f-bfbb-56f7c15f075b', 'Aerial', 3, 2, 1, '0827969777220'); INSERT INTO release_country (release, country, date_year, date_month, date_day) VALUES (3, 222, 2005, 11, 8); @@ -161,8 +163,8 @@ INSERT INTO medium (id, release, position, format, name) VALUES (4, 2, 2, 1, 'A INSERT INTO medium (id, release, position, format, name) VALUES (5, 3, 1, 1, 'A Sea of Honey'); INSERT INTO medium (id, release, position, format, name) VALUES (6, 3, 2, 1, 'A Sky of Honey'); -INSERT INTO recording (id, gid, name, artist_credit, length) VALUES - (2, '54b9d183-7dab-42ba-94a3-7388a66604b8', 'King of the Mountain', 3, 293720); +INSERT INTO recording (id, gid, name, artist_credit, length, last_updated) VALUES + (2, '54b9d183-7dab-42ba-94a3-7388a66604b8', 'King of the Mountain', 3, 293720, '2020-02-20 19:00:00'); INSERT INTO recording (id, gid, name, artist_credit, length) VALUES (3, '659f405b-b4ee-4033-868a-0daa27784b89', 'π', 3, 369680); INSERT INTO recording (id, gid, name, artist_credit, length) VALUES @@ -195,8 +197,8 @@ INSERT INTO recording (id, gid, name, artist_credit, length) VALUES INSERT INTO recording (id, gid, name, artist_credit, length) VALUES (17, '1539ac10-5081-4469-b8f2-c5896132724e', 'Aerial', 3, 472880); -INSERT INTO recording_alias (id, name, sort_name, recording, edits_pending) - VALUES (1, 'King of the Mt.', 'King of the Mt.', 2, 0); +INSERT INTO recording_alias (id, name, sort_name, recording, type, edits_pending) + VALUES (1, 'King of the Mt.', 'King of the Mt.', 2, 1, 0); INSERT INTO track (id, gid, medium, position, number, recording, name, artist_credit, length) VALUES (4, '39164965-d4bd-49e6-925d-72026ad03dce', 3, 1, 1, 2, 'King of the Mountain', 3, 293720); INSERT INTO track (id, gid, medium, position, number, recording, name, artist_credit, length) VALUES (5, '82edb036-4097-484d-ac8a-cf4971451ca0', 3, 2, 2, 3, 'π', 3, 369680); diff --git a/mbslave/sql/SetSequences.sql b/mbslave/sql/SetSequences.sql index 44b7763..6aa8c87 100644 --- a/mbslave/sql/SetSequences.sql +++ b/mbslave/sql/SetSequences.sql @@ -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); diff --git a/mbslave/sql/TruncateTables.sql b/mbslave/sql/TruncateTables.sql index e2d83b0..6a7ab11 100644 --- a/mbslave/sql/TruncateTables.sql +++ b/mbslave/sql/TruncateTables.sql @@ -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; @@ -94,10 +95,6 @@ TRUNCATE TABLE editor_subscribe_label RESTART IDENTITY CASCADE; TRUNCATE TABLE editor_subscribe_label_deleted RESTART IDENTITY CASCADE; TRUNCATE TABLE editor_subscribe_series RESTART IDENTITY CASCADE; TRUNCATE TABLE editor_subscribe_series_deleted RESTART IDENTITY CASCADE; -TRUNCATE TABLE editor_watch_artist RESTART IDENTITY CASCADE; -TRUNCATE TABLE editor_watch_preferences RESTART IDENTITY CASCADE; -TRUNCATE TABLE editor_watch_release_group_type RESTART IDENTITY CASCADE; -TRUNCATE TABLE editor_watch_release_status RESTART IDENTITY CASCADE; TRUNCATE TABLE event RESTART IDENTITY CASCADE; TRUNCATE TABLE event_alias RESTART IDENTITY CASCADE; TRUNCATE TABLE event_alias_type RESTART IDENTITY CASCADE; @@ -355,6 +352,7 @@ TRUNCATE TABLE tag_relation RESTART IDENTITY CASCADE; TRUNCATE TABLE track RESTART IDENTITY CASCADE; TRUNCATE TABLE track_gid_redirect RESTART IDENTITY CASCADE; TRUNCATE TABLE track_raw RESTART IDENTITY CASCADE; +TRUNCATE TABLE unreferenced_row_log RESTART IDENTITY CASCADE; TRUNCATE TABLE url RESTART IDENTITY CASCADE; TRUNCATE TABLE url_gid_redirect RESTART IDENTITY CASCADE; TRUNCATE TABLE vote RESTART IDENTITY CASCADE; diff --git a/mbslave/sql/dbmirror2/MasterSetup.sql b/mbslave/sql/dbmirror2/MasterSetup.sql index c4fed3c..d4c6481 100644 --- a/mbslave/sql/dbmirror2/MasterSetup.sql +++ b/mbslave/sql/dbmirror2/MasterSetup.sql @@ -71,19 +71,6 @@ BEGIN pg_get_serial_sequence('dbmirror2.pending_data', 'seqid') ); - INSERT INTO dbmirror2.pending_keys (tablename, keys) - VALUES ( - _tablename, - ( - SELECT array_agg(column_name) - FROM dbmirror2.column_info - WHERE table_schema = TG_TABLE_SCHEMA - AND table_name = TG_TABLE_NAME - AND is_primary = TRUE - ) - ) - ON CONFLICT DO NOTHING; - INSERT INTO dbmirror2.pending_ts (xid, ts) VALUES (txid_current(), transaction_timestamp()) ON CONFLICT DO NOTHING; diff --git a/mbslave/sql/dbmirror2/README b/mbslave/sql/dbmirror2/README index 62b6330..1598c4a 100644 --- a/mbslave/sql/dbmirror2/README +++ b/mbslave/sql/dbmirror2/README @@ -1,5 +1,5 @@ ReplicationSetup.sql and MasterSetup.sql are copied from -https://github.com/metabrainz/dbmirror2, commit 7ba6422. (These are the only +https://github.com/metabrainz/dbmirror2, commit eda9923. (These are the only two files we need, and submodules are "difficult.") This is not a fork; please do not make any changes to the files here without diff --git a/mbslave/sql/updates/20130309-migrate-transclusion-table.pl b/mbslave/sql/updates/20130309-migrate-transclusion-table.pl index 4f1b6ea..7884e70 100755 --- a/mbslave/sql/updates/20130309-migrate-transclusion-table.pl +++ b/mbslave/sql/updates/20130309-migrate-transclusion-table.pl @@ -2,6 +2,7 @@ use strict; use warnings; +use English; use MusicBrainz::Server::Context; use DBDefs; @@ -33,10 +34,10 @@ sub _load_index_from_disk { my $index_file = DBDefs->STATIC_FILES_DIR . '/wikidocs/index.txt'; if (!open(FILE, "<" . $index_file)) { - warn "Could not open wikitrans index file '$index_file': $!."; + warn "Could not open wikitrans index file '$index_file': $OS_ERROR."; return {}; } - my $data = do { local $/; }; + my $data = do { local $INPUT_RECORD_SEPARATOR; }; close(FILE); return _parse_index($data); diff --git a/mbslave/sql/updates/20130313-bcrypt-passwords.pl b/mbslave/sql/updates/20130313-bcrypt-passwords.pl index 319c522..050c455 100755 --- a/mbslave/sql/updates/20130313-bcrypt-passwords.pl +++ b/mbslave/sql/updates/20130313-bcrypt-passwords.pl @@ -3,11 +3,12 @@ use Authen::Passphrase::BlowfishCrypt; use Authen::Passphrase::RejectAll; +use English; use MusicBrainz::Server::Context; use Sql; use Try::Tiny; -$| = 1; +$OUTPUT_AUTOFLUSH = 1; my $c = MusicBrainz::Server::Context->create_script_context; diff --git a/mbslave/sql/updates/20130322-init-bundled-replication.pl b/mbslave/sql/updates/20130322-init-bundled-replication.pl deleted file mode 100755 index 978f10b..0000000 --- a/mbslave/sql/updates/20130322-init-bundled-replication.pl +++ /dev/null @@ -1,16 +0,0 @@ -#!/usr/bin/perl -use strict; -use warnings; - -use DBDefs; -use MusicBrainz::Server::Context; - -my $c = MusicBrainz::Server::Context->create_script_context; - -my $replication_sequence = $c->sql->select_single_value('SELECT current_replication_sequence FROM replication_control'); -my $FTP_DATA_DIR = `grep FTP_DATA_DIR admin/config.sh`; -$FTP_DATA_DIR =~ s/^FTP_DATA_DIR=//; -chomp $FTP_DATA_DIR; - -system("./admin/replication/BundleReplicationPackets $FTP_DATA_DIR/replication --period daily --start $replication_sequence"); -system("./admin/replication/BundleReplicationPackets $FTP_DATA_DIR/replication --period weekly --start $replication_sequence"); diff --git a/mbslave/sql/updates/20130724-refresh-release_meta-asin.sql b/mbslave/sql/updates/20130724-refresh-release_meta-asin.sql index a140e6a..1859099 100644 --- a/mbslave/sql/updates/20130724-refresh-release_meta-asin.sql +++ b/mbslave/sql/updates/20130724-refresh-release_meta-asin.sql @@ -6,7 +6,7 @@ FROM ( FROM ( SELECT entity0 AS release, array_agg( - regexp_replace(url.url, E'^http://(?:www.)?(.*?)(?:\\:[0-9]+)?/.*/([0-9B][0-9A-Z]{9})(?:[^0-9A-Z]|$)', E'\\2') + regexp_replace(url.url, E'^https?://(?:www.)?(.*?)(?:\\:[0-9]+)?/.*/([0-9B][0-9A-Z]{9})(?:[^0-9A-Z]|$)', E'\\2') ORDER BY l_release_url.last_updated DESC ) asins FROM l_release_url diff --git a/mbslave/sql/updates/20130906-materialise-recording-lengths.pl b/mbslave/sql/updates/20130906-materialise-recording-lengths.pl index 0509c69..71e1ef1 100755 --- a/mbslave/sql/updates/20130906-materialise-recording-lengths.pl +++ b/mbslave/sql/updates/20130906-materialise-recording-lengths.pl @@ -1,10 +1,11 @@ use strict; use warnings; +use English; use MusicBrainz::Server::Context; use Sql; -$| = 1; +$OUTPUT_AUTOFLUSH = 1; my $c = MusicBrainz::Server::Context->create_script_context; my $i = 0; diff --git a/mbslave/sql/updates/20211203-mbs-11312-standalone.sql b/mbslave/sql/updates/20211203-mbs-11312-standalone.sql new file mode 100644 index 0000000..f3f80f0 --- /dev/null +++ b/mbslave/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; diff --git a/mbslave/sql/updates/20211203-mbs-11312.sql b/mbslave/sql/updates/20211203-mbs-11312.sql new file mode 100644 index 0000000..26f57b6 --- /dev/null +++ b/mbslave/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; diff --git a/mbslave/sql/updates/20220207-mbs-12224-mirror.sql b/mbslave/sql/updates/20220207-mbs-12224-mirror.sql index 7b5c2fa..651622f 100644 --- a/mbslave/sql/updates/20220207-mbs-12224-mirror.sql +++ b/mbslave/sql/updates/20220207-mbs-12224-mirror.sql @@ -2,168 +2,6 @@ BEGIN; -DELETE FROM area_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM area_tag_raw r - WHERE r.area = a.area AND r.tag = a.tag -); - -UPDATE area_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM area_tag_raw r - WHERE r.area = a.area AND r.tag = a.tag - GROUP BY r.area, r.tag -); - -DELETE FROM artist_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM artist_tag_raw r - WHERE r.artist = a.artist AND r.tag = a.tag -); - -UPDATE artist_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM artist_tag_raw r - WHERE r.artist = a.artist AND r.tag = a.tag - GROUP BY r.artist, r.tag -); - -DELETE FROM event_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM event_tag_raw r - WHERE r.event = a.event AND r.tag = a.tag -); - -UPDATE event_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM event_tag_raw r - WHERE r.event = a.event AND r.tag = a.tag - GROUP BY r.event, r.tag -); - -DELETE FROM instrument_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM instrument_tag_raw r - WHERE r.instrument = a.instrument AND r.tag = a.tag -); - -UPDATE instrument_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM instrument_tag_raw r - WHERE r.instrument = a.instrument AND r.tag = a.tag - GROUP BY r.instrument, r.tag -); - -DELETE FROM label_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM label_tag_raw r - WHERE r.label = a.label AND r.tag = a.tag -); - -UPDATE label_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM label_tag_raw r - WHERE r.label = a.label AND r.tag = a.tag - GROUP BY r.label, r.tag -); - -DELETE FROM place_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM place_tag_raw r - WHERE r.place = a.place AND r.tag = a.tag -); - -UPDATE place_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM place_tag_raw r - WHERE r.place = a.place AND r.tag = a.tag - GROUP BY r.place, r.tag -); - -DELETE FROM recording_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM recording_tag_raw r - WHERE r.recording = a.recording AND r.tag = a.tag -); - -UPDATE recording_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM recording_tag_raw r - WHERE r.recording = a.recording AND r.tag = a.tag - GROUP BY r.recording, r.tag -); - -DELETE FROM release_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM release_tag_raw r - WHERE r.release = a.release AND r.tag = a.tag -); - -UPDATE release_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM release_tag_raw r - WHERE r.release = a.release AND r.tag = a.tag - GROUP BY r.release, r.tag -); - -DELETE FROM release_group_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM release_group_tag_raw r - WHERE r.release_group = a.release_group AND r.tag = a.tag -); - -UPDATE release_group_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM release_group_tag_raw r - WHERE r.release_group = a.release_group AND r.tag = a.tag - GROUP BY r.release_group, r.tag -); - -DELETE FROM series_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM series_tag_raw r - WHERE r.series = a.series AND r.tag = a.tag -); - -UPDATE series_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM series_tag_raw r - WHERE r.series = a.series AND r.tag = a.tag - GROUP BY r.series, r.tag -); - -DELETE FROM work_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM work_tag_raw r - WHERE r.work = a.work AND r.tag = a.tag -); - -UPDATE work_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM work_tag_raw r - WHERE r.work = a.work AND r.tag = a.tag - GROUP BY r.work, r.tag -); - -UPDATE tag t SET ref_count = ( - (SELECT count(*) FROM area_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM artist_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM event_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM instrument_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM label_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM place_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM recording_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM release_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM release_group_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM series_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM work_tag_raw r WHERE r.tag = t.id) -); - --- Unused, non-replicated table that holds FKs to tag. -TRUNCATE tag_relation; - -DELETE FROM tag WHERE ref_count = 0; - CREATE TYPE taggable_entity_type AS ENUM ( 'area', 'artist', diff --git a/mbslave/sql/updates/20220207-mbs-12224-standalone.sql b/mbslave/sql/updates/20220207-mbs-12224-standalone.sql index 0fd2878..4eded9e 100644 --- a/mbslave/sql/updates/20220207-mbs-12224-standalone.sql +++ b/mbslave/sql/updates/20220207-mbs-12224-standalone.sql @@ -2,6 +2,168 @@ BEGIN; +DELETE FROM area_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM area_tag_raw r + WHERE r.area = a.area AND r.tag = a.tag +); + +UPDATE area_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM area_tag_raw r + WHERE r.area = a.area AND r.tag = a.tag + GROUP BY r.area, r.tag +); + +DELETE FROM artist_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM artist_tag_raw r + WHERE r.artist = a.artist AND r.tag = a.tag +); + +UPDATE artist_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM artist_tag_raw r + WHERE r.artist = a.artist AND r.tag = a.tag + GROUP BY r.artist, r.tag +); + +DELETE FROM event_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM event_tag_raw r + WHERE r.event = a.event AND r.tag = a.tag +); + +UPDATE event_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM event_tag_raw r + WHERE r.event = a.event AND r.tag = a.tag + GROUP BY r.event, r.tag +); + +DELETE FROM instrument_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM instrument_tag_raw r + WHERE r.instrument = a.instrument AND r.tag = a.tag +); + +UPDATE instrument_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM instrument_tag_raw r + WHERE r.instrument = a.instrument AND r.tag = a.tag + GROUP BY r.instrument, r.tag +); + +DELETE FROM label_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM label_tag_raw r + WHERE r.label = a.label AND r.tag = a.tag +); + +UPDATE label_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM label_tag_raw r + WHERE r.label = a.label AND r.tag = a.tag + GROUP BY r.label, r.tag +); + +DELETE FROM place_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM place_tag_raw r + WHERE r.place = a.place AND r.tag = a.tag +); + +UPDATE place_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM place_tag_raw r + WHERE r.place = a.place AND r.tag = a.tag + GROUP BY r.place, r.tag +); + +DELETE FROM recording_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM recording_tag_raw r + WHERE r.recording = a.recording AND r.tag = a.tag +); + +UPDATE recording_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM recording_tag_raw r + WHERE r.recording = a.recording AND r.tag = a.tag + GROUP BY r.recording, r.tag +); + +DELETE FROM release_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM release_tag_raw r + WHERE r.release = a.release AND r.tag = a.tag +); + +UPDATE release_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM release_tag_raw r + WHERE r.release = a.release AND r.tag = a.tag + GROUP BY r.release, r.tag +); + +DELETE FROM release_group_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM release_group_tag_raw r + WHERE r.release_group = a.release_group AND r.tag = a.tag +); + +UPDATE release_group_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM release_group_tag_raw r + WHERE r.release_group = a.release_group AND r.tag = a.tag + GROUP BY r.release_group, r.tag +); + +DELETE FROM series_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM series_tag_raw r + WHERE r.series = a.series AND r.tag = a.tag +); + +UPDATE series_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM series_tag_raw r + WHERE r.series = a.series AND r.tag = a.tag + GROUP BY r.series, r.tag +); + +DELETE FROM work_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM work_tag_raw r + WHERE r.work = a.work AND r.tag = a.tag +); + +UPDATE work_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM work_tag_raw r + WHERE r.work = a.work AND r.tag = a.tag + GROUP BY r.work, r.tag +); + +UPDATE tag t SET ref_count = ( + (SELECT count(*) FROM area_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM artist_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM event_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM instrument_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM label_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM place_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM recording_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM release_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM release_group_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM series_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM work_tag_raw r WHERE r.tag = t.id) +); + +-- Unused, non-replicated table that holds FKs to tag. +TRUNCATE tag_relation; + +DELETE FROM tag WHERE ref_count = 0; + CREATE TRIGGER update_counts_for_insert AFTER INSERT ON area_tag_raw FOR EACH ROW EXECUTE PROCEDURE update_tag_counts_for_raw_insert('area'); diff --git a/mbslave/sql/updates/20220720-mbs-12508.sh b/mbslave/sql/updates/20220720-mbs-12508.sh new file mode 100755 index 0000000..2c1cc60 --- /dev/null +++ b/mbslave/sql/updates/20220720-mbs-12508.sh @@ -0,0 +1,155 @@ +#!/usr/bin/env bash + +set -e + +MB_SERVER_ROOT=$(cd "$(dirname "${BASH_SOURCE[0]}")/../../../" && pwd) +cd "$MB_SERVER_ROOT" + +: ${REPLICATION_TYPE:=$(perl -Ilib -e 'use DBDefs; print DBDefs->REPLICATION_TYPE;')} + +if [ "$REPLICATION_TYPE" != '2' ] +then + echo `date`: This is not a mirror server. Exiting. + exit 1 +fi + +: ${DATABASE:=MAINTENANCE} + +. admin/functions.sh + +if [[ ! -v TEMP_DIR ]] +then + make_temp_dir +fi + +DUMP_FILE="$TEMP_DIR"/mbdump-derived.tar.bz2 + +if [[ ! -f "$DUMP_FILE" ]] +then + FTP_DATA_URL='http://ftp.musicbrainz.org/pub/musicbrainz/data' + + echo `date`: Retrieving LATEST from FTP + LATEST=$(curl "$FTP_DATA_URL"/fullexport/LATEST) + + echo `date`: Retrieving mbdump-derived.tar.bz2 from FTP + curl \ + -o "$DUMP_FILE" \ + "$FTP_DATA_URL"/fullexport/"$LATEST"/mbdump-derived.tar.bz2 +fi + +echo `date`: Saving existing tag data to tmp tables +OUTPUT=$( + cat <<'SQL' | ./admin/psql "$DATABASE" 2>&1 +\set ON_ERROR_STOP 1 +CREATE TABLE IF NOT EXISTS tmp_area_tag_mbs_12508 AS TABLE area_tag; +CREATE TABLE IF NOT EXISTS tmp_artist_tag_mbs_12508 AS TABLE artist_tag; +CREATE TABLE IF NOT EXISTS tmp_event_tag_mbs_12508 AS TABLE event_tag; +CREATE TABLE IF NOT EXISTS tmp_instrument_tag_mbs_12508 AS TABLE instrument_tag; +CREATE TABLE IF NOT EXISTS tmp_label_tag_mbs_12508 AS TABLE label_tag; +CREATE TABLE IF NOT EXISTS tmp_place_tag_mbs_12508 AS TABLE place_tag; +CREATE TABLE IF NOT EXISTS tmp_recording_tag_mbs_12508 AS TABLE recording_tag; +CREATE TABLE IF NOT EXISTS tmp_release_tag_mbs_12508 AS TABLE release_tag; +CREATE TABLE IF NOT EXISTS tmp_release_group_tag_mbs_12508 AS TABLE release_group_tag; +CREATE TABLE IF NOT EXISTS tmp_series_tag_mbs_12508 AS TABLE series_tag; +CREATE TABLE IF NOT EXISTS tmp_work_tag_mbs_12508 AS TABLE work_tag; +CREATE TABLE IF NOT EXISTS tmp_tag_mbs_12508 AS TABLE tag; +SQL +) || ( echo "$OUTPUT" && exit 1 ) + +echo `date`: Clearing existing tag tables +OUTPUT=$( + cat <<'SQL' | ./admin/psql "$DATABASE" 2>&1 +\set ON_ERROR_STOP 1 +TRUNCATE area_tag; +TRUNCATE artist_tag; +TRUNCATE event_tag; +TRUNCATE instrument_tag; +TRUNCATE label_tag; +TRUNCATE place_tag; +TRUNCATE recording_tag; +TRUNCATE release_tag; +TRUNCATE release_group_tag; +TRUNCATE series_tag; +TRUNCATE work_tag; +TRUNCATE tag CASCADE; +-- Shouldn't exist on mirrors, but just in case +DROP TRIGGER IF EXISTS delete_unused_tag ON tag; +SQL +) || ( echo "$OUTPUT" && exit 1 ) + +echo `date`: Importing tag data from latest dump +./admin/MBImport.pl \ + --tmp-dir "$TEMP_DIR" \ + --database "$DATABASE" \ + --table tag \ + --table area_tag \ + --table artist_tag \ + --table event_tag \ + --table instrument_tag \ + --table label_tag \ + --table place_tag \ + --table recording_tag \ + --table release_tag \ + --table release_group_tag \ + --table series_tag \ + --table work_tag \ + --noupdate-replication-control \ + "$DUMP_FILE" + +echo `date`: Restoring saved tag data from tmp tables +OUTPUT=$( +cat <<'SQL' | ./admin/psql "$DATABASE" 2>&1 +\set ON_ERROR_STOP 1 + +INSERT INTO area_tag (SELECT * FROM tmp_area_tag_mbs_12508) + ON CONFLICT (area, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_area_tag_mbs_12508; + +INSERT INTO artist_tag (SELECT * FROM tmp_artist_tag_mbs_12508) + ON CONFLICT (artist, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_artist_tag_mbs_12508; + +INSERT INTO event_tag (SELECT * FROM tmp_event_tag_mbs_12508) + ON CONFLICT (event, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_event_tag_mbs_12508; + +INSERT INTO instrument_tag (SELECT * FROM tmp_instrument_tag_mbs_12508) + ON CONFLICT (instrument, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_instrument_tag_mbs_12508; + +INSERT INTO label_tag (SELECT * FROM tmp_label_tag_mbs_12508) + ON CONFLICT (label, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_label_tag_mbs_12508; + +INSERT INTO place_tag (SELECT * FROM tmp_place_tag_mbs_12508) + ON CONFLICT (place, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_place_tag_mbs_12508; + +INSERT INTO recording_tag (SELECT * FROM tmp_recording_tag_mbs_12508) + ON CONFLICT (recording, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_recording_tag_mbs_12508; + +INSERT INTO release_tag (SELECT * FROM tmp_release_tag_mbs_12508) + ON CONFLICT (release, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_release_tag_mbs_12508; + +INSERT INTO release_group_tag (SELECT * FROM tmp_release_group_tag_mbs_12508) + ON CONFLICT (release_group, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_release_group_tag_mbs_12508; + +INSERT INTO series_tag (SELECT * FROM tmp_series_tag_mbs_12508) + ON CONFLICT (series, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_series_tag_mbs_12508; + +INSERT INTO work_tag (SELECT * FROM tmp_work_tag_mbs_12508) + ON CONFLICT (work, tag) DO UPDATE SET count = excluded.count, last_updated = excluded.last_updated; +DROP TABLE tmp_work_tag_mbs_12508; + +DELETE FROM tag WHERE id IN (SELECT id FROM tmp_tag_mbs_12508); +INSERT INTO tag (SELECT * FROM tmp_tag_mbs_12508) + ON CONFLICT (name) DO UPDATE SET id = excluded.id, ref_count = excluded.ref_count; +DROP TABLE tmp_tag_mbs_12508; +SQL +) || ( echo "$OUTPUT" && exit 1 ) + +rm "$DUMP_FILE" diff --git a/mbslave/sql/updates/20220802-mbs-12497.sql b/mbslave/sql/updates/20220802-mbs-12497.sql new file mode 100644 index 0000000..365180a --- /dev/null +++ b/mbslave/sql/updates/20220802-mbs-12497.sql @@ -0,0 +1,28 @@ +\set ON_ERROR_STOP 1 + +BEGIN; + +CREATE TABLE IF NOT EXISTS unreferenced_row_log ( + table_name VARCHAR NOT NULL, -- PK + row_id INTEGER NOT NULL, -- PK + inserted TIMESTAMP WITH TIME ZONE DEFAULT NOW() +); + +CREATE OR REPLACE FUNCTION dec_ref_count(tbl varchar, row_id integer, val integer) RETURNS void AS $$ +DECLARE + ref_count integer; +BEGIN + -- decrement ref_count for the old name, + -- or prepare it for deletion if ref_count would drop to 0 + EXECUTE 'SELECT ref_count FROM ' || tbl || ' WHERE id = ' || row_id || ' FOR UPDATE' INTO ref_count; + IF ref_count <= val THEN + EXECUTE 'INSERT INTO unreferenced_row_log (table_name, row_id) VALUES ($1, $2)' USING tbl, row_id; + END IF; + EXECUTE 'UPDATE ' || tbl || ' SET ref_count = ref_count - ' || val || ' WHERE id = ' || row_id; + RETURN; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE INDEX IF NOT EXISTS unreferenced_row_log_idx_inserted ON unreferenced_row_log USING BRIN (inserted); + +COMMIT; diff --git a/mbslave/sql/updates/20220927-mbs-12573.sql b/mbslave/sql/updates/20220927-mbs-12573.sql new file mode 100644 index 0000000..5ac2e19 --- /dev/null +++ b/mbslave/sql/updates/20220927-mbs-12573.sql @@ -0,0 +1,7 @@ +\set ON_ERROR_STOP 1 + +BEGIN; + +ALTER TABLE cdtoc DROP COLUMN degraded CASCADE; + +COMMIT; diff --git a/mbslave/sql/updates/20221114-mbs-12704.sql b/mbslave/sql/updates/20221114-mbs-12704.sql new file mode 100644 index 0000000..f5aa2a7 --- /dev/null +++ b/mbslave/sql/updates/20221114-mbs-12704.sql @@ -0,0 +1,14 @@ +\set ON_ERROR_STOP 1 + +BEGIN; + +DROP TRIGGER IF EXISTS a_ins_editor ON editor; + +DROP FUNCTION a_ins_editor(); + +DROP TABLE editor_watch_artist; +DROP TABLE editor_watch_preferences; +DROP TABLE editor_watch_release_group_type; +DROP TABLE editor_watch_release_status; + +COMMIT; diff --git a/mbslave/sql/updates/20230320-mbs-12800.sql b/mbslave/sql/updates/20230320-mbs-12800.sql new file mode 100644 index 0000000..e2f0f4b --- /dev/null +++ b/mbslave/sql/updates/20230320-mbs-12800.sql @@ -0,0 +1,97 @@ +\set ON_ERROR_STOP 1 + +BEGIN; + +-- Update the release update function to reset dates when status set to/from cancelled +CREATE OR REPLACE FUNCTION a_upd_release() RETURNS trigger AS $$ +BEGIN + IF NEW.artist_credit != OLD.artist_credit THEN + PERFORM dec_ref_count('artist_credit', OLD.artist_credit, 1); + PERFORM inc_ref_count('artist_credit', NEW.artist_credit, 1); + END IF; + IF ( + NEW.status IS DISTINCT FROM OLD.status AND + (NEW.status = 6 OR OLD.status = 6) + ) THEN + PERFORM set_release_first_release_date(NEW.id); + + -- avoid executing it twice as this will be executed a few lines below if RG changes + IF NEW.release_group = OLD.release_group THEN + PERFORM set_release_group_first_release_date(NEW.release_group); + END IF; + + PERFORM set_releases_recordings_first_release_dates(ARRAY[NEW.id]); + END IF; + IF NEW.release_group != OLD.release_group THEN + -- release group is changed, decrement release_count in the original RG, increment in the new one + UPDATE release_group_meta SET release_count = release_count - 1 WHERE id = OLD.release_group; + UPDATE release_group_meta SET release_count = release_count + 1 WHERE id = NEW.release_group; + PERFORM set_release_group_first_release_date(OLD.release_group); + PERFORM set_release_group_first_release_date(NEW.release_group); + END IF; + IF ( + NEW.status IS DISTINCT FROM OLD.status OR + NEW.release_group != OLD.release_group OR + NEW.artist_credit != OLD.artist_credit + ) THEN + INSERT INTO artist_release_group_pending_update + VALUES (NEW.release_group), (OLD.release_group); + END IF; + IF ( + NEW.barcode IS DISTINCT FROM OLD.barcode OR + NEW.name != OLD.name OR + NEW.artist_credit != OLD.artist_credit + ) THEN + INSERT INTO artist_release_pending_update VALUES (OLD.id); + END IF; + RETURN NULL; +END; +$$ LANGUAGE 'plpgsql'; + +-- Update the release dates function to ignore cancelled releases +CREATE OR REPLACE FUNCTION get_release_first_release_date_rows(condition TEXT) +RETURNS SETOF release_first_release_date AS $$ +BEGIN + RETURN QUERY EXECUTE ' + SELECT DISTINCT ON (release) release, + date_year AS year, + date_month AS month, + date_day AS day + FROM ( + SELECT release, date_year, date_month, date_day FROM release_country + WHERE (date_year IS NOT NULL OR date_month IS NOT NULL OR date_day IS NOT NULL) + UNION ALL + SELECT release, date_year, date_month, date_day FROM release_unknown_country + ) all_dates + WHERE ' || condition || + ' AND NOT EXISTS ( + SELECT TRUE + FROM release + WHERE release.id = all_dates.release + AND status = 6 + ) + ORDER BY release, year NULLS LAST, month NULLS LAST, day NULLS LAST'; +END; +$$ LANGUAGE 'plpgsql' STRICT; + +-- Delete rows already in release_first_release_date for cancelled releases +DELETE FROM release_first_release_date +WHERE release IN ( + SELECT id + FROM release + WHERE status = 6 +); + +-- Rerun set_release_group_first_release_date for release groups with cancelled releases +SELECT set_release_group_first_release_date(release_group) FROM ( + SELECT DISTINCT release_group + FROM release + WHERE status = 6 +) rgs_with_cancelled_releases; + +-- Rerun set_releases_recordings_first_release_dates for cancelled releases +SELECT set_releases_recordings_first_release_dates(array_agg(id)) + FROM release + WHERE status = 6; + +COMMIT; diff --git a/mbslave/sql/updates/20230423-nix-pending-keys-insertion.sql b/mbslave/sql/updates/20230423-nix-pending-keys-insertion.sql new file mode 100644 index 0000000..57bcd31 --- /dev/null +++ b/mbslave/sql/updates/20230423-nix-pending-keys-insertion.sql @@ -0,0 +1,130 @@ +\set ON_ERROR_STOP 1 + +BEGIN; + +CREATE OR REPLACE FUNCTION dbmirror2.recordchange() +RETURNS trigger AS $$ +DECLARE + -- prefixed with an underscore to disambiguate it from the column names + -- pending_data.tablename and pending_keys.tablename + _tablename TEXT; + keys TEXT[]; + jsonquery TEXT; + olddata JSON; + newdata JSON; + -- prefixed with 'x' to avoid conflict with column name in queries + xoldctid TID; + nextseqid BIGINT; + -- out-of-order seqid + oooseqid BIGINT; + oootrgdepth INTEGER; + pdcursor NO SCROLL CURSOR (oooseqid INTEGER) FOR + SELECT seqid + FROM dbmirror2.pending_data + WHERE xid = txid_current() + AND seqid >= oooseqid + ORDER BY seqid DESC + FOR UPDATE; +BEGIN + _tablename := ( + quote_ident(TG_TABLE_SCHEMA) || '.' || quote_ident(TG_TABLE_NAME) + ); + + nextseqid := nextval( + pg_get_serial_sequence('dbmirror2.pending_data', 'seqid') + ); + + INSERT INTO dbmirror2.pending_ts (xid, ts) + VALUES (txid_current(), transaction_timestamp()) + ON CONFLICT DO NOTHING; + + jsonquery := ( + SELECT format( + 'SELECT json_build_object(%1$s)', + array_to_string( + array_agg( + format('%1$L, ($1).%1$I', column_name) ORDER BY position + ), + ', ' + ) + ) + FROM dbmirror2.column_info + WHERE table_schema = TG_TABLE_SCHEMA AND table_name = TG_TABLE_NAME + ); + + IF TG_OP != 'INSERT' THEN + EXECUTE jsonquery INTO olddata USING OLD; + + xoldctid := OLD.ctid; + END IF; + + IF TG_OP != 'DELETE' THEN + EXECUTE jsonquery INTO newdata USING NEW; + + -- Detect out-of-order operations caused by cascading triggers. + -- + -- When row-level AFTER triggers are cascaded, the innermost trigger + -- runs first. This means we may potentially see an UPDATE or DELETE + -- of a row version that hasn't been added yet. + -- + -- We detect this by storing OLD.ctid for every operation. (The ctid + -- is a tuple describing the physical location of the row version. We + -- only need this to be stable for the lifetime of the current + -- transaction.) We then check if there's a previous operation whose + -- OLD ctid equals our NEW ctid; these are then known to be out-of- + -- order. This previous operation's seqid is assigned to `oooseqid` + -- ("out-of-order seqid"). + -- + -- The order is fixed by shifting the sequence IDs from the current + -- transaction until they're corrected. The current-last operation + -- assumes `nextseqid`, the second-to-last assumes the seqid of the + -- last, and so on until `oooseqid` is unused. We then insert our new + -- operation with `oooseqid`. + -- + -- Since we're never modifying `pending_data` rows inserted by other + -- transactions, this shifting should be safe. + SELECT seqid, trgdepth INTO oooseqid, oootrgdepth + FROM dbmirror2.pending_data + WHERE xid = txid_current() + AND tablename = _tablename + AND oldctid = NEW.ctid; + + IF FOUND THEN + IF oootrgdepth IS NOT NULL AND oootrgdepth <= pg_trigger_depth() THEN + -- This should never happen! Cascading triggers are the only + -- known way for operations to arrive out of order. This + -- warning must be investigated if it's ever logged. + RAISE WARNING 'oootrgdepth (%) <= pg_trigger_depth() (%) (% ON %, OLD: %, NEW: %)', + oootrgdepth, pg_trigger_depth(), TG_OP, _tablename, OLD, NEW; + END IF; + + FOR pdrecord IN pdcursor (oooseqid := oooseqid) LOOP + UPDATE dbmirror2.pending_data + SET seqid = nextseqid + WHERE CURRENT OF pdcursor; + + nextseqid := pdrecord.seqid; + END LOOP; + + ASSERT (nextseqid = oooseqid); + END IF; + END IF; + + INSERT INTO dbmirror2.pending_data + (seqid, tablename, op, xid, olddata, newdata, oldctid, trgdepth) + VALUES ( + nextseqid, + _tablename, + lower(left(TG_OP, 1)), + txid_current(), + olddata, + newdata, + xoldctid, + pg_trigger_depth() + ); + + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +COMMIT; diff --git a/mbslave/sql/updates/schema-change/20.mirror.sql b/mbslave/sql/updates/schema-change/20.all.sql similarity index 100% rename from mbslave/sql/updates/schema-change/20.mirror.sql rename to mbslave/sql/updates/schema-change/20.all.sql diff --git a/mbslave/sql/updates/schema-change/20.standalone.sql b/mbslave/sql/updates/schema-change/20.master_and_standalone.sql similarity index 100% rename from mbslave/sql/updates/schema-change/20.standalone.sql rename to mbslave/sql/updates/schema-change/20.master_and_standalone.sql diff --git a/mbslave/sql/updates/schema-change/21.mirror.sql b/mbslave/sql/updates/schema-change/21.all.sql similarity index 100% rename from mbslave/sql/updates/schema-change/21.mirror.sql rename to mbslave/sql/updates/schema-change/21.all.sql diff --git a/mbslave/sql/updates/schema-change/21.standalone.sql b/mbslave/sql/updates/schema-change/21.master_and_standalone.sql similarity index 100% rename from mbslave/sql/updates/schema-change/21.standalone.sql rename to mbslave/sql/updates/schema-change/21.master_and_standalone.sql diff --git a/mbslave/sql/updates/schema-change/22.mirror.sql b/mbslave/sql/updates/schema-change/22.all.sql similarity index 100% rename from mbslave/sql/updates/schema-change/22.mirror.sql rename to mbslave/sql/updates/schema-change/22.all.sql diff --git a/mbslave/sql/updates/schema-change/22.standalone.sql b/mbslave/sql/updates/schema-change/22.master_and_standalone.sql similarity index 100% rename from mbslave/sql/updates/schema-change/22.standalone.sql rename to mbslave/sql/updates/schema-change/22.master_and_standalone.sql diff --git a/mbslave/sql/updates/schema-change/23.mirror.sql b/mbslave/sql/updates/schema-change/23.all.sql similarity index 100% rename from mbslave/sql/updates/schema-change/23.mirror.sql rename to mbslave/sql/updates/schema-change/23.all.sql diff --git a/mbslave/sql/updates/schema-change/23.extensions.sql b/mbslave/sql/updates/schema-change/23.all_extensions.sql similarity index 100% rename from mbslave/sql/updates/schema-change/23.extensions.sql rename to mbslave/sql/updates/schema-change/23.all_extensions.sql diff --git a/mbslave/sql/updates/schema-change/23.standalone.sql b/mbslave/sql/updates/schema-change/23.master_and_standalone.sql similarity index 100% rename from mbslave/sql/updates/schema-change/23.standalone.sql rename to mbslave/sql/updates/schema-change/23.master_and_standalone.sql diff --git a/mbslave/sql/updates/schema-change/24.mirror.sql b/mbslave/sql/updates/schema-change/24.all.sql similarity index 100% rename from mbslave/sql/updates/schema-change/24.mirror.sql rename to mbslave/sql/updates/schema-change/24.all.sql diff --git a/mbslave/sql/updates/schema-change/24.standalone.sql b/mbslave/sql/updates/schema-change/24.master_and_standalone.sql similarity index 100% rename from mbslave/sql/updates/schema-change/24.standalone.sql rename to mbslave/sql/updates/schema-change/24.master_and_standalone.sql diff --git a/mbslave/sql/updates/schema-change/25.mirror.sql b/mbslave/sql/updates/schema-change/25.all.sql similarity index 100% rename from mbslave/sql/updates/schema-change/25.mirror.sql rename to mbslave/sql/updates/schema-change/25.all.sql diff --git a/mbslave/sql/updates/schema-change/25.standalone.sql b/mbslave/sql/updates/schema-change/25.master_and_standalone.sql similarity index 100% rename from mbslave/sql/updates/schema-change/25.standalone.sql rename to mbslave/sql/updates/schema-change/25.master_and_standalone.sql diff --git a/mbslave/sql/updates/schema-change/26.mirror.sql b/mbslave/sql/updates/schema-change/26.all.sql similarity index 100% rename from mbslave/sql/updates/schema-change/26.mirror.sql rename to mbslave/sql/updates/schema-change/26.all.sql diff --git a/mbslave/sql/updates/schema-change/26.standalone.sql b/mbslave/sql/updates/schema-change/26.master_and_standalone.sql similarity index 100% rename from mbslave/sql/updates/schema-change/26.standalone.sql rename to mbslave/sql/updates/schema-change/26.master_and_standalone.sql diff --git a/mbslave/sql/updates/schema-change/27.mirror.sql b/mbslave/sql/updates/schema-change/27.all.sql similarity index 94% rename from mbslave/sql/updates/schema-change/27.mirror.sql rename to mbslave/sql/updates/schema-change/27.all.sql index ca299f2..19135f1 100644 --- a/mbslave/sql/updates/schema-change/27.mirror.sql +++ b/mbslave/sql/updates/schema-change/27.all.sql @@ -254,168 +254,6 @@ $$ LANGUAGE 'plpgsql'; SELECT '20220207-mbs-12224-mirror.sql'; -DELETE FROM area_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM area_tag_raw r - WHERE r.area = a.area AND r.tag = a.tag -); - -UPDATE area_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM area_tag_raw r - WHERE r.area = a.area AND r.tag = a.tag - GROUP BY r.area, r.tag -); - -DELETE FROM artist_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM artist_tag_raw r - WHERE r.artist = a.artist AND r.tag = a.tag -); - -UPDATE artist_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM artist_tag_raw r - WHERE r.artist = a.artist AND r.tag = a.tag - GROUP BY r.artist, r.tag -); - -DELETE FROM event_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM event_tag_raw r - WHERE r.event = a.event AND r.tag = a.tag -); - -UPDATE event_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM event_tag_raw r - WHERE r.event = a.event AND r.tag = a.tag - GROUP BY r.event, r.tag -); - -DELETE FROM instrument_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM instrument_tag_raw r - WHERE r.instrument = a.instrument AND r.tag = a.tag -); - -UPDATE instrument_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM instrument_tag_raw r - WHERE r.instrument = a.instrument AND r.tag = a.tag - GROUP BY r.instrument, r.tag -); - -DELETE FROM label_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM label_tag_raw r - WHERE r.label = a.label AND r.tag = a.tag -); - -UPDATE label_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM label_tag_raw r - WHERE r.label = a.label AND r.tag = a.tag - GROUP BY r.label, r.tag -); - -DELETE FROM place_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM place_tag_raw r - WHERE r.place = a.place AND r.tag = a.tag -); - -UPDATE place_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM place_tag_raw r - WHERE r.place = a.place AND r.tag = a.tag - GROUP BY r.place, r.tag -); - -DELETE FROM recording_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM recording_tag_raw r - WHERE r.recording = a.recording AND r.tag = a.tag -); - -UPDATE recording_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM recording_tag_raw r - WHERE r.recording = a.recording AND r.tag = a.tag - GROUP BY r.recording, r.tag -); - -DELETE FROM release_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM release_tag_raw r - WHERE r.release = a.release AND r.tag = a.tag -); - -UPDATE release_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM release_tag_raw r - WHERE r.release = a.release AND r.tag = a.tag - GROUP BY r.release, r.tag -); - -DELETE FROM release_group_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM release_group_tag_raw r - WHERE r.release_group = a.release_group AND r.tag = a.tag -); - -UPDATE release_group_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM release_group_tag_raw r - WHERE r.release_group = a.release_group AND r.tag = a.tag - GROUP BY r.release_group, r.tag -); - -DELETE FROM series_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM series_tag_raw r - WHERE r.series = a.series AND r.tag = a.tag -); - -UPDATE series_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM series_tag_raw r - WHERE r.series = a.series AND r.tag = a.tag - GROUP BY r.series, r.tag -); - -DELETE FROM work_tag a WHERE NOT EXISTS ( - SELECT 1 - FROM work_tag_raw r - WHERE r.work = a.work AND r.tag = a.tag -); - -UPDATE work_tag a SET count = ( - SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) - FROM work_tag_raw r - WHERE r.work = a.work AND r.tag = a.tag - GROUP BY r.work, r.tag -); - -UPDATE tag t SET ref_count = ( - (SELECT count(*) FROM area_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM artist_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM event_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM instrument_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM label_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM place_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM recording_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM release_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM release_group_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM series_tag_raw r WHERE r.tag = t.id) + - (SELECT count(*) FROM work_tag_raw r WHERE r.tag = t.id) -); - --- Unused, non-replicated table that holds FKs to tag. -TRUNCATE tag_relation; - -DELETE FROM tag WHERE ref_count = 0; - CREATE TYPE taggable_entity_type AS ENUM ( 'area', 'artist', diff --git a/mbslave/sql/updates/schema-change/27.standalone.sql b/mbslave/sql/updates/schema-change/27.master_and_standalone.sql similarity index 95% rename from mbslave/sql/updates/schema-change/27.standalone.sql rename to mbslave/sql/updates/schema-change/27.master_and_standalone.sql index 9a7dc4f..d56abbb 100644 --- a/mbslave/sql/updates/schema-change/27.standalone.sql +++ b/mbslave/sql/updates/schema-change/27.master_and_standalone.sql @@ -560,6 +560,168 @@ ALTER TABLE tag SELECT '20220207-mbs-12224-standalone.sql'; +DELETE FROM area_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM area_tag_raw r + WHERE r.area = a.area AND r.tag = a.tag +); + +UPDATE area_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM area_tag_raw r + WHERE r.area = a.area AND r.tag = a.tag + GROUP BY r.area, r.tag +); + +DELETE FROM artist_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM artist_tag_raw r + WHERE r.artist = a.artist AND r.tag = a.tag +); + +UPDATE artist_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM artist_tag_raw r + WHERE r.artist = a.artist AND r.tag = a.tag + GROUP BY r.artist, r.tag +); + +DELETE FROM event_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM event_tag_raw r + WHERE r.event = a.event AND r.tag = a.tag +); + +UPDATE event_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM event_tag_raw r + WHERE r.event = a.event AND r.tag = a.tag + GROUP BY r.event, r.tag +); + +DELETE FROM instrument_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM instrument_tag_raw r + WHERE r.instrument = a.instrument AND r.tag = a.tag +); + +UPDATE instrument_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM instrument_tag_raw r + WHERE r.instrument = a.instrument AND r.tag = a.tag + GROUP BY r.instrument, r.tag +); + +DELETE FROM label_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM label_tag_raw r + WHERE r.label = a.label AND r.tag = a.tag +); + +UPDATE label_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM label_tag_raw r + WHERE r.label = a.label AND r.tag = a.tag + GROUP BY r.label, r.tag +); + +DELETE FROM place_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM place_tag_raw r + WHERE r.place = a.place AND r.tag = a.tag +); + +UPDATE place_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM place_tag_raw r + WHERE r.place = a.place AND r.tag = a.tag + GROUP BY r.place, r.tag +); + +DELETE FROM recording_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM recording_tag_raw r + WHERE r.recording = a.recording AND r.tag = a.tag +); + +UPDATE recording_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM recording_tag_raw r + WHERE r.recording = a.recording AND r.tag = a.tag + GROUP BY r.recording, r.tag +); + +DELETE FROM release_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM release_tag_raw r + WHERE r.release = a.release AND r.tag = a.tag +); + +UPDATE release_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM release_tag_raw r + WHERE r.release = a.release AND r.tag = a.tag + GROUP BY r.release, r.tag +); + +DELETE FROM release_group_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM release_group_tag_raw r + WHERE r.release_group = a.release_group AND r.tag = a.tag +); + +UPDATE release_group_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM release_group_tag_raw r + WHERE r.release_group = a.release_group AND r.tag = a.tag + GROUP BY r.release_group, r.tag +); + +DELETE FROM series_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM series_tag_raw r + WHERE r.series = a.series AND r.tag = a.tag +); + +UPDATE series_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM series_tag_raw r + WHERE r.series = a.series AND r.tag = a.tag + GROUP BY r.series, r.tag +); + +DELETE FROM work_tag a WHERE NOT EXISTS ( + SELECT 1 + FROM work_tag_raw r + WHERE r.work = a.work AND r.tag = a.tag +); + +UPDATE work_tag a SET count = ( + SELECT sum(CASE WHEN is_upvote THEN 1 ELSE -1 END) + FROM work_tag_raw r + WHERE r.work = a.work AND r.tag = a.tag + GROUP BY r.work, r.tag +); + +UPDATE tag t SET ref_count = ( + (SELECT count(*) FROM area_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM artist_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM event_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM instrument_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM label_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM place_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM recording_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM release_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM release_group_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM series_tag_raw r WHERE r.tag = t.id) + + (SELECT count(*) FROM work_tag_raw r WHERE r.tag = t.id) +); + +-- Unused, non-replicated table that holds FKs to tag. +TRUNCATE tag_relation; + +DELETE FROM tag WHERE ref_count = 0; + CREATE TRIGGER update_counts_for_insert AFTER INSERT ON area_tag_raw FOR EACH ROW EXECUTE PROCEDURE update_tag_counts_for_raw_insert('area'); diff --git a/mbslave/sql/updates/schema-change/28.all.sql b/mbslave/sql/updates/schema-change/28.all.sql new file mode 100644 index 0000000..dbd87cd --- /dev/null +++ b/mbslave/sql/updates/schema-change/28.all.sql @@ -0,0 +1,188 @@ +-- Generated by CompileSchemaScripts.pl from: +-- 20211203-mbs-11312.sql +-- 20220802-mbs-12497.sql +-- 20220927-mbs-12573.sql +-- 20221114-mbs-12704.sql +-- 20230320-mbs-12800.sql +\set ON_ERROR_STOP 1 +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'; + + +CREATE TABLE IF NOT EXISTS unreferenced_row_log ( + table_name VARCHAR NOT NULL, -- PK + row_id INTEGER NOT NULL, -- PK + inserted TIMESTAMP WITH TIME ZONE DEFAULT NOW() +); + +CREATE OR REPLACE FUNCTION dec_ref_count(tbl varchar, row_id integer, val integer) RETURNS void AS $$ +DECLARE + ref_count integer; +BEGIN + -- decrement ref_count for the old name, + -- or prepare it for deletion if ref_count would drop to 0 + EXECUTE 'SELECT ref_count FROM ' || tbl || ' WHERE id = ' || row_id || ' FOR UPDATE' INTO ref_count; + IF ref_count <= val THEN + EXECUTE 'INSERT INTO unreferenced_row_log (table_name, row_id) VALUES ($1, $2)' USING tbl, row_id; + END IF; + EXECUTE 'UPDATE ' || tbl || ' SET ref_count = ref_count - ' || val || ' WHERE id = ' || row_id; + RETURN; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE INDEX IF NOT EXISTS unreferenced_row_log_idx_inserted ON unreferenced_row_log USING BRIN (inserted); + +-------------------------------------------------------------------------------- +SELECT '20220927-mbs-12573.sql'; + + +ALTER TABLE cdtoc DROP COLUMN degraded CASCADE; + +-------------------------------------------------------------------------------- +SELECT '20221114-mbs-12704.sql'; + + +DROP TRIGGER IF EXISTS a_ins_editor ON editor; + +DROP FUNCTION a_ins_editor(); + +DROP TABLE editor_watch_artist; +DROP TABLE editor_watch_preferences; +DROP TABLE editor_watch_release_group_type; +DROP TABLE editor_watch_release_status; + +-------------------------------------------------------------------------------- +SELECT '20230320-mbs-12800.sql'; + + +-- Update the release update function to reset dates when status set to/from cancelled +CREATE OR REPLACE FUNCTION a_upd_release() RETURNS trigger AS $$ +BEGIN + IF NEW.artist_credit != OLD.artist_credit THEN + PERFORM dec_ref_count('artist_credit', OLD.artist_credit, 1); + PERFORM inc_ref_count('artist_credit', NEW.artist_credit, 1); + END IF; + IF ( + NEW.status IS DISTINCT FROM OLD.status AND + (NEW.status = 6 OR OLD.status = 6) + ) THEN + PERFORM set_release_first_release_date(NEW.id); + + -- avoid executing it twice as this will be executed a few lines below if RG changes + IF NEW.release_group = OLD.release_group THEN + PERFORM set_release_group_first_release_date(NEW.release_group); + END IF; + + PERFORM set_releases_recordings_first_release_dates(ARRAY[NEW.id]); + END IF; + IF NEW.release_group != OLD.release_group THEN + -- release group is changed, decrement release_count in the original RG, increment in the new one + UPDATE release_group_meta SET release_count = release_count - 1 WHERE id = OLD.release_group; + UPDATE release_group_meta SET release_count = release_count + 1 WHERE id = NEW.release_group; + PERFORM set_release_group_first_release_date(OLD.release_group); + PERFORM set_release_group_first_release_date(NEW.release_group); + END IF; + IF ( + NEW.status IS DISTINCT FROM OLD.status OR + NEW.release_group != OLD.release_group OR + NEW.artist_credit != OLD.artist_credit + ) THEN + INSERT INTO artist_release_group_pending_update + VALUES (NEW.release_group), (OLD.release_group); + END IF; + IF ( + NEW.barcode IS DISTINCT FROM OLD.barcode OR + NEW.name != OLD.name OR + NEW.artist_credit != OLD.artist_credit + ) THEN + INSERT INTO artist_release_pending_update VALUES (OLD.id); + END IF; + RETURN NULL; +END; +$$ LANGUAGE 'plpgsql'; + +-- Update the release dates function to ignore cancelled releases +CREATE OR REPLACE FUNCTION get_release_first_release_date_rows(condition TEXT) +RETURNS SETOF release_first_release_date AS $$ +BEGIN + RETURN QUERY EXECUTE ' + SELECT DISTINCT ON (release) release, + date_year AS year, + date_month AS month, + date_day AS day + FROM ( + SELECT release, date_year, date_month, date_day FROM release_country + WHERE (date_year IS NOT NULL OR date_month IS NOT NULL OR date_day IS NOT NULL) + UNION ALL + SELECT release, date_year, date_month, date_day FROM release_unknown_country + ) all_dates + WHERE ' || condition || + ' AND NOT EXISTS ( + SELECT TRUE + FROM release + WHERE release.id = all_dates.release + AND status = 6 + ) + ORDER BY release, year NULLS LAST, month NULLS LAST, day NULLS LAST'; +END; +$$ LANGUAGE 'plpgsql' STRICT; + +-- Delete rows already in release_first_release_date for cancelled releases +DELETE FROM release_first_release_date +WHERE release IN ( + SELECT id + FROM release + WHERE status = 6 +); + +-- Rerun set_release_group_first_release_date for release groups with cancelled releases +SELECT set_release_group_first_release_date(release_group) FROM ( + SELECT DISTINCT release_group + FROM release + WHERE status = 6 +) rgs_with_cancelled_releases; + +-- Rerun set_releases_recordings_first_release_dates for cancelled releases +SELECT set_releases_recordings_first_release_dates(array_agg(id)) + FROM release + WHERE status = 6; + +COMMIT; diff --git a/mbslave/sql/updates/schema-change/28.master_and_standalone.sql b/mbslave/sql/updates/schema-change/28.master_and_standalone.sql new file mode 100644 index 0000000..c289a92 --- /dev/null +++ b/mbslave/sql/updates/schema-change/28.master_and_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; diff --git a/mbslave/sql/updates/schema-change/28.master_only.sql b/mbslave/sql/updates/schema-change/28.master_only.sql new file mode 100644 index 0000000..0f7bf02 --- /dev/null +++ b/mbslave/sql/updates/schema-change/28.master_only.sql @@ -0,0 +1,136 @@ +-- Generated by CompileSchemaScripts.pl from: +-- 20230423-nix-pending-keys-insertion.sql +\set ON_ERROR_STOP 1 +BEGIN; +SET search_path = musicbrainz, public; +SET LOCAL statement_timeout = 0; +-------------------------------------------------------------------------------- +SELECT '20230423-nix-pending-keys-insertion.sql'; + + +CREATE OR REPLACE FUNCTION dbmirror2.recordchange() +RETURNS trigger AS $$ +DECLARE + -- prefixed with an underscore to disambiguate it from the column names + -- pending_data.tablename and pending_keys.tablename + _tablename TEXT; + keys TEXT[]; + jsonquery TEXT; + olddata JSON; + newdata JSON; + -- prefixed with 'x' to avoid conflict with column name in queries + xoldctid TID; + nextseqid BIGINT; + -- out-of-order seqid + oooseqid BIGINT; + oootrgdepth INTEGER; + pdcursor NO SCROLL CURSOR (oooseqid INTEGER) FOR + SELECT seqid + FROM dbmirror2.pending_data + WHERE xid = txid_current() + AND seqid >= oooseqid + ORDER BY seqid DESC + FOR UPDATE; +BEGIN + _tablename := ( + quote_ident(TG_TABLE_SCHEMA) || '.' || quote_ident(TG_TABLE_NAME) + ); + + nextseqid := nextval( + pg_get_serial_sequence('dbmirror2.pending_data', 'seqid') + ); + + INSERT INTO dbmirror2.pending_ts (xid, ts) + VALUES (txid_current(), transaction_timestamp()) + ON CONFLICT DO NOTHING; + + jsonquery := ( + SELECT format( + 'SELECT json_build_object(%1$s)', + array_to_string( + array_agg( + format('%1$L, ($1).%1$I', column_name) ORDER BY position + ), + ', ' + ) + ) + FROM dbmirror2.column_info + WHERE table_schema = TG_TABLE_SCHEMA AND table_name = TG_TABLE_NAME + ); + + IF TG_OP != 'INSERT' THEN + EXECUTE jsonquery INTO olddata USING OLD; + + xoldctid := OLD.ctid; + END IF; + + IF TG_OP != 'DELETE' THEN + EXECUTE jsonquery INTO newdata USING NEW; + + -- Detect out-of-order operations caused by cascading triggers. + -- + -- When row-level AFTER triggers are cascaded, the innermost trigger + -- runs first. This means we may potentially see an UPDATE or DELETE + -- of a row version that hasn't been added yet. + -- + -- We detect this by storing OLD.ctid for every operation. (The ctid + -- is a tuple describing the physical location of the row version. We + -- only need this to be stable for the lifetime of the current + -- transaction.) We then check if there's a previous operation whose + -- OLD ctid equals our NEW ctid; these are then known to be out-of- + -- order. This previous operation's seqid is assigned to `oooseqid` + -- ("out-of-order seqid"). + -- + -- The order is fixed by shifting the sequence IDs from the current + -- transaction until they're corrected. The current-last operation + -- assumes `nextseqid`, the second-to-last assumes the seqid of the + -- last, and so on until `oooseqid` is unused. We then insert our new + -- operation with `oooseqid`. + -- + -- Since we're never modifying `pending_data` rows inserted by other + -- transactions, this shifting should be safe. + SELECT seqid, trgdepth INTO oooseqid, oootrgdepth + FROM dbmirror2.pending_data + WHERE xid = txid_current() + AND tablename = _tablename + AND oldctid = NEW.ctid; + + IF FOUND THEN + IF oootrgdepth IS NOT NULL AND oootrgdepth <= pg_trigger_depth() THEN + -- This should never happen! Cascading triggers are the only + -- known way for operations to arrive out of order. This + -- warning must be investigated if it's ever logged. + RAISE WARNING 'oootrgdepth (%) <= pg_trigger_depth() (%) (% ON %, OLD: %, NEW: %)', + oootrgdepth, pg_trigger_depth(), TG_OP, _tablename, OLD, NEW; + END IF; + + FOR pdrecord IN pdcursor (oooseqid := oooseqid) LOOP + UPDATE dbmirror2.pending_data + SET seqid = nextseqid + WHERE CURRENT OF pdcursor; + + nextseqid := pdrecord.seqid; + END LOOP; + + ASSERT (nextseqid = oooseqid); + END IF; + END IF; + + INSERT INTO dbmirror2.pending_data + (seqid, tablename, op, xid, olddata, newdata, oldctid, trgdepth) + VALUES ( + nextseqid, + _tablename, + lower(left(TG_OP, 1)), + txid_current(), + olddata, + newdata, + xoldctid, + pg_trigger_depth() + ); + + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +COMMIT; diff --git a/scripts/update_sql.sh b/scripts/update_sql.sh index c3e7ab9..f6e971d 100755 --- a/scripts/update_sql.sh +++ b/scripts/update_sql.sh @@ -1,6 +1,6 @@ #!/bin/sh -cd $(dirname $0)/../mbdata +cd $(dirname $0)/../mbslave rm -rf sql From c4dcc4af34936e862488a3a017cc560405ecfc2d Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Luk=C3=A1=C5=A1=20Lalinsk=C3=BD?= Date: Mon, 22 May 2023 16:37:58 +0200 Subject: [PATCH 2/2] Update instructions --- README.rst | 8 ++++++++ 1 file changed, 8 insertions(+) diff --git a/README.rst b/README.rst index 3a47bc2..cb5747e 100644 --- a/README.rst +++ b/README.rst @@ -82,6 +82,14 @@ When the MusicBrainz database schema changes, the replication will stop working. This is usually announced on the `MusicBrainz blog `__. When it happens, you need to upgrade the database. +Release 2023-05-22 (28) +~~~~~~~~~~~~~~~~~~~~~~~ + +Run the upgrade scripts:: + + mbslave psql -f updates/schema-change/28.all.sql + echo 'UPDATE replication_control SET current_schema_sequence = 28;' | mbslave psql + Release 2022-05-16 (27) ~~~~~~~~~~~~~~~~~~~~~~~