From 6024bc6d76971bd1e61962da4c13a0b7b7f14301 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Stefan=20Fu=C3=9Fenegger?= Date: Fri, 17 May 2024 11:48:38 +0200 Subject: [PATCH] update schema 2024-05-13 SQL files --- mbslave/sql/CreateConstraints.sql | 5 +- mbslave/sql/CreateFKConstraints.sql | 10 ++++ mbslave/sql/CreateIndexes.sql | 2 +- mbslave/sql/CreatePrimaryKeys.sql | 1 + mbslave/sql/CreateTables.sql | 11 +++- mbslave/sql/DropFKConstraints.sql | 2 + mbslave/sql/DropPrimaryKeys.sql | 1 + mbslave/sql/DropTables.sql | 1 + mbslave/sql/InsertTestData.sql | 3 + mbslave/sql/TruncateTables.sql | 1 + mbslave/sql/updates/20220720-mbs-12508.sh | 4 +- .../20231005-edit-data-idx-link-type.sql | 17 ++++++ mbslave/sql/updates/20240220-mbs-13403.sql | 7 +++ .../sql/updates/20240223-mbs-13421-fks.sql | 17 ++++++ mbslave/sql/updates/20240223-mbs-13421.sql | 20 +++++++ .../sql/updates/20240319-mbs-13514-mirror.sql | 9 +++ mbslave/sql/updates/20240319-mbs-13514.sql | 7 +++ mbslave/sql/updates/schema-change/29.all.sql | 59 +++++++++++++++++++ .../29.master_and_standalone.sql | 30 ++++++++++ 19 files changed, 200 insertions(+), 7 deletions(-) create mode 100644 mbslave/sql/updates/20231005-edit-data-idx-link-type.sql create mode 100644 mbslave/sql/updates/20240220-mbs-13403.sql create mode 100644 mbslave/sql/updates/20240223-mbs-13421-fks.sql create mode 100644 mbslave/sql/updates/20240223-mbs-13421.sql create mode 100644 mbslave/sql/updates/20240319-mbs-13514-mirror.sql create mode 100644 mbslave/sql/updates/20240319-mbs-13514.sql create mode 100644 mbslave/sql/updates/schema-change/29.all.sql create mode 100644 mbslave/sql/updates/schema-change/29.master_and_standalone.sql diff --git a/mbslave/sql/CreateConstraints.sql b/mbslave/sql/CreateConstraints.sql index 52e3294..5df4283 100644 --- a/mbslave/sql/CreateConstraints.sql +++ b/mbslave/sql/CreateConstraints.sql @@ -41,7 +41,7 @@ ALTER TABLE artist_alias ALTER TABLE editor_collection_type ADD CONSTRAINT allowed_collection_entity_type CHECK ( entity_type IN ( - 'area', 'artist', 'event', 'instrument', 'label', + 'area', 'artist', 'event', 'genre', 'instrument', 'label', 'place', 'recording', 'release', 'release_group', 'series', 'work' ) @@ -76,7 +76,8 @@ ALTER TABLE instrument_alias ALTER TABLE label ADD CONSTRAINT control_for_whitespace CHECK (controlled_for_whitespace(name)), - ADD CONSTRAINT only_non_empty CHECK (name != ''); + ADD CONSTRAINT only_non_empty CHECK (name != ''), + ADD CONSTRAINT label_code_length CHECK (label_code > 0 AND label_code < 1000000); ALTER TABLE label_alias ADD CONSTRAINT control_for_whitespace CHECK (controlled_for_whitespace(name)), diff --git a/mbslave/sql/CreateFKConstraints.sql b/mbslave/sql/CreateFKConstraints.sql index 0acd3f2..eef896f 100644 --- a/mbslave/sql/CreateFKConstraints.sql +++ b/mbslave/sql/CreateFKConstraints.sql @@ -667,6 +667,16 @@ ALTER TABLE editor_collection_event FOREIGN KEY (event) REFERENCES event(id); +ALTER TABLE editor_collection_genre + ADD CONSTRAINT editor_collection_genre_fk_collection + FOREIGN KEY (collection) + REFERENCES editor_collection(id); + +ALTER TABLE editor_collection_genre + ADD CONSTRAINT editor_collection_genre_fk_genre + FOREIGN KEY (genre) + REFERENCES genre(id); + ALTER TABLE editor_collection_gid_redirect ADD CONSTRAINT editor_collection_gid_redirect_fk_new_id FOREIGN KEY (new_id) diff --git a/mbslave/sql/CreateIndexes.sql b/mbslave/sql/CreateIndexes.sql index d1bf178..b5c0b69 100644 --- a/mbslave/sql/CreateIndexes.sql +++ b/mbslave/sql/CreateIndexes.sql @@ -147,7 +147,7 @@ CREATE INDEX edit_data_idx_link_type ON edit_data USING GIN ( (data#>>'{link,link_type,id}')::int, (data#>>'{old,link_type,id}')::int, (data#>>'{new,link_type,id}')::int, - (data#>>'{relationship,link_type,id}')::int + (data#>>'{relationship,link,type,id}')::int ], NULL) ); diff --git a/mbslave/sql/CreatePrimaryKeys.sql b/mbslave/sql/CreatePrimaryKeys.sql index 7d7988f..8724bab 100644 --- a/mbslave/sql/CreatePrimaryKeys.sql +++ b/mbslave/sql/CreatePrimaryKeys.sql @@ -70,6 +70,7 @@ ALTER TABLE editor_collection_artist ADD CONSTRAINT editor_collection_artist_pke ALTER TABLE editor_collection_collaborator ADD CONSTRAINT editor_collection_collaborator_pkey PRIMARY KEY (collection, editor); ALTER TABLE editor_collection_deleted_entity ADD CONSTRAINT editor_collection_deleted_entity_pkey PRIMARY KEY (collection, gid); ALTER TABLE editor_collection_event ADD CONSTRAINT editor_collection_event_pkey PRIMARY KEY (collection, event); +ALTER TABLE editor_collection_genre ADD CONSTRAINT editor_collection_genre_pkey PRIMARY KEY (collection, genre); ALTER TABLE editor_collection_gid_redirect ADD CONSTRAINT editor_collection_gid_redirect_pkey PRIMARY KEY (gid); ALTER TABLE editor_collection_instrument ADD CONSTRAINT editor_collection_instrument_pkey PRIMARY KEY (collection, instrument); ALTER TABLE editor_collection_label ADD CONSTRAINT editor_collection_label_pkey PRIMARY KEY (collection, label); diff --git a/mbslave/sql/CreateTables.sql b/mbslave/sql/CreateTables.sql index c9d24e0..7f3fabe 100644 --- a/mbslave/sql/CreateTables.sql +++ b/mbslave/sql/CreateTables.sql @@ -2467,7 +2467,7 @@ CREATE TABLE label ( -- replicate (verbose) end_date_year SMALLINT, end_date_month SMALLINT, end_date_day SMALLINT, - label_code INTEGER CHECK (label_code > 0 AND label_code < 100000), + label_code INTEGER, type INTEGER, -- references label_type.id area INTEGER, -- references area.id comment VARCHAR(255) NOT NULL DEFAULT '', @@ -2729,7 +2729,6 @@ CREATE TABLE link_type ( -- replicate link_phrase VARCHAR(255) NOT NULL, reverse_link_phrase VARCHAR(255) NOT NULL, long_link_phrase VARCHAR(255) NOT NULL, - priority INTEGER NOT NULL DEFAULT 0, last_updated TIMESTAMP WITH TIME ZONE DEFAULT NOW(), is_deprecated BOOLEAN NOT NULL DEFAULT false, has_dates BOOLEAN NOT NULL DEFAULT true, @@ -2801,6 +2800,14 @@ CREATE TABLE editor_collection_event ( comment TEXT DEFAULT '' NOT NULL ); +CREATE TABLE editor_collection_genre ( + collection INTEGER NOT NULL, -- PK, references editor_collection.id + genre INTEGER NOT NULL, -- PK, references genre.id + added TIMESTAMP WITH TIME ZONE DEFAULT NOW(), + position INTEGER NOT NULL DEFAULT 0 CHECK (position >= 0), + comment TEXT DEFAULT '' NOT NULL +); + CREATE TABLE editor_collection_instrument ( collection INTEGER NOT NULL, -- PK, references editor_collection.id instrument INTEGER NOT NULL, -- PK, references instrument.id diff --git a/mbslave/sql/DropFKConstraints.sql b/mbslave/sql/DropFKConstraints.sql index ba59b6c..0d4eadf 100644 --- a/mbslave/sql/DropFKConstraints.sql +++ b/mbslave/sql/DropFKConstraints.sql @@ -130,6 +130,8 @@ ALTER TABLE editor_collection_deleted_entity DROP CONSTRAINT IF EXISTS editor_co ALTER TABLE editor_collection_deleted_entity DROP CONSTRAINT IF EXISTS editor_collection_deleted_entity_fk_gid; ALTER TABLE editor_collection_event DROP CONSTRAINT IF EXISTS editor_collection_event_fk_collection; ALTER TABLE editor_collection_event DROP CONSTRAINT IF EXISTS editor_collection_event_fk_event; +ALTER TABLE editor_collection_genre DROP CONSTRAINT IF EXISTS editor_collection_genre_fk_collection; +ALTER TABLE editor_collection_genre DROP CONSTRAINT IF EXISTS editor_collection_genre_fk_genre; ALTER TABLE editor_collection_gid_redirect DROP CONSTRAINT IF EXISTS editor_collection_gid_redirect_fk_new_id; ALTER TABLE editor_collection_instrument DROP CONSTRAINT IF EXISTS editor_collection_instrument_fk_collection; ALTER TABLE editor_collection_instrument DROP CONSTRAINT IF EXISTS editor_collection_instrument_fk_instrument; diff --git a/mbslave/sql/DropPrimaryKeys.sql b/mbslave/sql/DropPrimaryKeys.sql index da41d8b..b16b198 100644 --- a/mbslave/sql/DropPrimaryKeys.sql +++ b/mbslave/sql/DropPrimaryKeys.sql @@ -70,6 +70,7 @@ ALTER TABLE editor_collection_artist DROP CONSTRAINT IF EXISTS editor_collection ALTER TABLE editor_collection_collaborator DROP CONSTRAINT IF EXISTS editor_collection_collaborator_pkey; ALTER TABLE editor_collection_deleted_entity DROP CONSTRAINT IF EXISTS editor_collection_deleted_entity_pkey; ALTER TABLE editor_collection_event DROP CONSTRAINT IF EXISTS editor_collection_event_pkey; +ALTER TABLE editor_collection_genre DROP CONSTRAINT IF EXISTS editor_collection_genre_pkey; ALTER TABLE editor_collection_gid_redirect DROP CONSTRAINT IF EXISTS editor_collection_gid_redirect_pkey; ALTER TABLE editor_collection_instrument DROP CONSTRAINT IF EXISTS editor_collection_instrument_pkey; ALTER TABLE editor_collection_label DROP CONSTRAINT IF EXISTS editor_collection_label_pkey; diff --git a/mbslave/sql/DropTables.sql b/mbslave/sql/DropTables.sql index a5f2617..8eb5357 100644 --- a/mbslave/sql/DropTables.sql +++ b/mbslave/sql/DropTables.sql @@ -74,6 +74,7 @@ DROP TABLE editor_collection_artist; DROP TABLE editor_collection_collaborator; DROP TABLE editor_collection_deleted_entity; DROP TABLE editor_collection_event; +DROP TABLE editor_collection_genre; DROP TABLE editor_collection_gid_redirect; DROP TABLE editor_collection_instrument; DROP TABLE editor_collection_label; diff --git a/mbslave/sql/InsertTestData.sql b/mbslave/sql/InsertTestData.sql index 9927e26..0fecd6c 100644 --- a/mbslave/sql/InsertTestData.sql +++ b/mbslave/sql/InsertTestData.sql @@ -253,6 +253,9 @@ INSERT INTO artist (id, gid, name, sort_name) INSERT INTO artist (id, gid, name, sort_name, comment) VALUES (9, '2fed031c-0e89-406e-b9f0-3d192637907a', 'Test Alias', 'Kate Bush', 'Second'); +INSERT INTO event (id, gid, name, begin_date_year, begin_date_month, begin_date_day, end_date_year, end_date_month, end_date_day, time, type, cancelled, setlist, comment, ended) + VALUES (59357, 'ca1d24c1-1999-46fd-8a95-3d4108df5cb2', 'BBC Open Music Prom', 2022, 9, 1, 2022, 9, 1, '19:30:00', 1, 'f', NULL, '2022, Prom 60', 't'); + INSERT INTO l_artist_recording (id, link, entity0, entity1) VALUES (1, 1, 8, 2); INSERT INTO l_artist_recording (id, link, entity0, entity1, edits_pending) VALUES (2, 1, 9, 2, 1); INSERT INTO l_artist_recording (id, link, entity0, entity1) VALUES (3, 2, 8, 3); diff --git a/mbslave/sql/TruncateTables.sql b/mbslave/sql/TruncateTables.sql index 6a7ab11..db1e112 100644 --- a/mbslave/sql/TruncateTables.sql +++ b/mbslave/sql/TruncateTables.sql @@ -74,6 +74,7 @@ TRUNCATE TABLE editor_collection_artist RESTART IDENTITY CASCADE; TRUNCATE TABLE editor_collection_collaborator RESTART IDENTITY CASCADE; TRUNCATE TABLE editor_collection_deleted_entity RESTART IDENTITY CASCADE; TRUNCATE TABLE editor_collection_event RESTART IDENTITY CASCADE; +TRUNCATE TABLE editor_collection_genre RESTART IDENTITY CASCADE; TRUNCATE TABLE editor_collection_gid_redirect RESTART IDENTITY CASCADE; TRUNCATE TABLE editor_collection_instrument RESTART IDENTITY CASCADE; TRUNCATE TABLE editor_collection_label RESTART IDENTITY CASCADE; diff --git a/mbslave/sql/updates/20220720-mbs-12508.sh b/mbslave/sql/updates/20220720-mbs-12508.sh index 2c1cc60..eafd9a7 100755 --- a/mbslave/sql/updates/20220720-mbs-12508.sh +++ b/mbslave/sql/updates/20220720-mbs-12508.sh @@ -29,10 +29,10 @@ then FTP_DATA_URL='http://ftp.musicbrainz.org/pub/musicbrainz/data' echo `date`: Retrieving LATEST from FTP - LATEST=$(curl "$FTP_DATA_URL"/fullexport/LATEST) + LATEST=$(curl -sSL "$FTP_DATA_URL"/fullexport/LATEST) echo `date`: Retrieving mbdump-derived.tar.bz2 from FTP - curl \ + curl -L \ -o "$DUMP_FILE" \ "$FTP_DATA_URL"/fullexport/"$LATEST"/mbdump-derived.tar.bz2 fi diff --git a/mbslave/sql/updates/20231005-edit-data-idx-link-type.sql b/mbslave/sql/updates/20231005-edit-data-idx-link-type.sql new file mode 100644 index 0000000..4912fbd --- /dev/null +++ b/mbslave/sql/updates/20231005-edit-data-idx-link-type.sql @@ -0,0 +1,17 @@ +\set ON_ERROR_STOP 1 + +BEGIN; + +DROP INDEX IF EXISTS edit_data_idx_link_type; + +CREATE INDEX edit_data_idx_link_type ON edit_data USING GIN ( + array_remove(ARRAY[ + (data#>>'{link_type,id}')::int, + (data#>>'{link,link_type,id}')::int, + (data#>>'{old,link_type,id}')::int, + (data#>>'{new,link_type,id}')::int, + (data#>>'{relationship,link,type,id}')::int + ], NULL) +); + +COMMIT; diff --git a/mbslave/sql/updates/20240220-mbs-13403.sql b/mbslave/sql/updates/20240220-mbs-13403.sql new file mode 100644 index 0000000..6f73abb --- /dev/null +++ b/mbslave/sql/updates/20240220-mbs-13403.sql @@ -0,0 +1,7 @@ +\set ON_ERROR_STOP 1 + +BEGIN; + +ALTER TABLE link_type DROP COLUMN priority CASCADE; + +COMMIT; diff --git a/mbslave/sql/updates/20240223-mbs-13421-fks.sql b/mbslave/sql/updates/20240223-mbs-13421-fks.sql new file mode 100644 index 0000000..ddd3ffb --- /dev/null +++ b/mbslave/sql/updates/20240223-mbs-13421-fks.sql @@ -0,0 +1,17 @@ +\set ON_ERROR_STOP 1 +BEGIN; + +ALTER TABLE editor_collection_type -- Already dropped in mirror update script + ADD CONSTRAINT allowed_collection_entity_type CHECK ( + entity_type IN ('area', 'artist', 'event', 'genre', 'instrument', 'label', 'place', 'recording', 'release', 'release_group', 'series', 'work') + ); + +ALTER TABLE editor_collection_genre + ADD CONSTRAINT editor_collection_genre_fk_collection + FOREIGN KEY (collection) + REFERENCES editor_collection(id), + ADD CONSTRAINT editor_collection_genre_fk_genre + FOREIGN KEY (genre) + REFERENCES genre(id); + +COMMIT; diff --git a/mbslave/sql/updates/20240223-mbs-13421.sql b/mbslave/sql/updates/20240223-mbs-13421.sql new file mode 100644 index 0000000..bed0675 --- /dev/null +++ b/mbslave/sql/updates/20240223-mbs-13421.sql @@ -0,0 +1,20 @@ +\set ON_ERROR_STOP 1 +BEGIN; + +CREATE TABLE editor_collection_genre ( + collection INTEGER NOT NULL, + genre INTEGER NOT NULL, + added TIMESTAMP WITH TIME ZONE DEFAULT NOW(), + position INTEGER NOT NULL DEFAULT 0 CHECK (position >= 0), + comment TEXT DEFAULT '' NOT NULL +); + +ALTER TABLE editor_collection_genre ADD CONSTRAINT editor_collection_genre_pkey PRIMARY KEY (collection, genre); + +ALTER TABLE editor_collection_type + DROP CONSTRAINT IF EXISTS allowed_collection_entity_type; + +INSERT INTO editor_collection_type (id, name, entity_type, parent, child_order, gid) + VALUES (16, 'Genre', 'genre', NULL, 2, generate_uuid_v3('6ba7b8119dad11d180b400c04fd430c8', 'editor_collection_type' || 16)); + +COMMIT; diff --git a/mbslave/sql/updates/20240319-mbs-13514-mirror.sql b/mbslave/sql/updates/20240319-mbs-13514-mirror.sql new file mode 100644 index 0000000..a4bf2dc --- /dev/null +++ b/mbslave/sql/updates/20240319-mbs-13514-mirror.sql @@ -0,0 +1,9 @@ +\set ON_ERROR_STOP 1 + +BEGIN; + +ALTER TABLE label DROP CONSTRAINT IF EXISTS label_label_code_check; + +ALTER TABLE label DROP CONSTRAINT IF EXISTS label_code_length; + +COMMIT; diff --git a/mbslave/sql/updates/20240319-mbs-13514.sql b/mbslave/sql/updates/20240319-mbs-13514.sql new file mode 100644 index 0000000..a3b24e6 --- /dev/null +++ b/mbslave/sql/updates/20240319-mbs-13514.sql @@ -0,0 +1,7 @@ +\set ON_ERROR_STOP 1 + +BEGIN; + +ALTER TABLE label ADD CONSTRAINT label_code_length CHECK (label_code > 0 AND label_code < 1000000); + +COMMIT; diff --git a/mbslave/sql/updates/schema-change/29.all.sql b/mbslave/sql/updates/schema-change/29.all.sql new file mode 100644 index 0000000..f04ab8e --- /dev/null +++ b/mbslave/sql/updates/schema-change/29.all.sql @@ -0,0 +1,59 @@ +-- Generated by CompileSchemaScripts.pl from: +-- 20231005-edit-data-idx-link-type.sql +-- 20240220-mbs-13403.sql +-- 20240223-mbs-13421.sql +-- 20240319-mbs-13514-mirror.sql +\set ON_ERROR_STOP 1 +BEGIN; +SET search_path = musicbrainz, public; +SET LOCAL statement_timeout = 0; +-------------------------------------------------------------------------------- +SELECT '20231005-edit-data-idx-link-type.sql'; + + +DROP INDEX IF EXISTS edit_data_idx_link_type; + +CREATE INDEX edit_data_idx_link_type ON edit_data USING GIN ( + array_remove(ARRAY[ + (data#>>'{link_type,id}')::int, + (data#>>'{link,link_type,id}')::int, + (data#>>'{old,link_type,id}')::int, + (data#>>'{new,link_type,id}')::int, + (data#>>'{relationship,link,type,id}')::int + ], NULL) +); + +-------------------------------------------------------------------------------- +SELECT '20240220-mbs-13403.sql'; + + +ALTER TABLE link_type DROP COLUMN priority CASCADE; + +-------------------------------------------------------------------------------- +SELECT '20240223-mbs-13421.sql'; + +CREATE TABLE editor_collection_genre ( + collection INTEGER NOT NULL, + genre INTEGER NOT NULL, + added TIMESTAMP WITH TIME ZONE DEFAULT NOW(), + position INTEGER NOT NULL DEFAULT 0 CHECK (position >= 0), + comment TEXT DEFAULT '' NOT NULL +); + +ALTER TABLE editor_collection_genre ADD CONSTRAINT editor_collection_genre_pkey PRIMARY KEY (collection, genre); + +ALTER TABLE editor_collection_type + DROP CONSTRAINT IF EXISTS allowed_collection_entity_type; + +INSERT INTO editor_collection_type (id, name, entity_type, parent, child_order, gid) + VALUES (16, 'Genre', 'genre', NULL, 2, generate_uuid_v3('6ba7b8119dad11d180b400c04fd430c8', 'editor_collection_type' || 16)); + +-------------------------------------------------------------------------------- +SELECT '20240319-mbs-13514-mirror.sql'; + + +ALTER TABLE label DROP CONSTRAINT IF EXISTS label_label_code_check; + +ALTER TABLE label DROP CONSTRAINT IF EXISTS label_code_length; + +COMMIT; diff --git a/mbslave/sql/updates/schema-change/29.master_and_standalone.sql b/mbslave/sql/updates/schema-change/29.master_and_standalone.sql new file mode 100644 index 0000000..fe1e45f --- /dev/null +++ b/mbslave/sql/updates/schema-change/29.master_and_standalone.sql @@ -0,0 +1,30 @@ +-- Generated by CompileSchemaScripts.pl from: +-- 20240223-mbs-13421-fks.sql +-- 20240319-mbs-13514.sql +\set ON_ERROR_STOP 1 +BEGIN; +SET search_path = musicbrainz, public; +SET LOCAL statement_timeout = 0; +-------------------------------------------------------------------------------- +SELECT '20240223-mbs-13421-fks.sql'; + +ALTER TABLE editor_collection_type -- Already dropped in mirror update script + ADD CONSTRAINT allowed_collection_entity_type CHECK ( + entity_type IN ('area', 'artist', 'event', 'genre', 'instrument', 'label', 'place', 'recording', 'release', 'release_group', 'series', 'work') + ); + +ALTER TABLE editor_collection_genre + ADD CONSTRAINT editor_collection_genre_fk_collection + FOREIGN KEY (collection) + REFERENCES editor_collection(id), + ADD CONSTRAINT editor_collection_genre_fk_genre + FOREIGN KEY (genre) + REFERENCES genre(id); + +-------------------------------------------------------------------------------- +SELECT '20240319-mbs-13514.sql'; + + +ALTER TABLE label ADD CONSTRAINT label_code_length CHECK (label_code > 0 AND label_code < 1000000); + +COMMIT;