Skip to content

Commit

Permalink
Update to MB DB Schema 29 - 2024 Q2
Browse files Browse the repository at this point in the history
  • Loading branch information
amCap1712 committed Jul 26, 2024
1 parent 81ccd5f commit 37d507a
Show file tree
Hide file tree
Showing 52 changed files with 348 additions and 14,171 deletions.
5 changes: 5 additions & 0 deletions CHANGELOG.rst
Original file line number Diff line number Diff line change
@@ -1,3 +1,8 @@
Version 29.0.0
==============

- Schema change 29.

Version 27.1.0
==============

Expand Down
2 changes: 1 addition & 1 deletion mbdata/__init__.py
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
# Copyright (C) 2013 Lukas Lalinsky
# Distributed under the MIT license, see the LICENSE file for details.

__version__ = "27.1.0"
__version__ = "29.0.0"
103 changes: 48 additions & 55 deletions mbdata/models.py
Original file line number Diff line number Diff line change
Expand Up @@ -838,7 +838,6 @@ class CDTOC(Base):
track_count = Column(Integer, nullable=False)
leadout_offset = Column(Integer, nullable=False)
track_offset = Column(Integer, nullable=False)
degraded = Column(Boolean, nullable=False, default=False, server_default=sql.false())
created = Column(DateTime(timezone=True), server_default=sql.func.now())


Expand Down Expand Up @@ -937,6 +936,26 @@ class EditNote(Base):
edit = relationship('Edit', foreign_keys=[edit_id], innerjoin=True)


class EditNoteChange(Base):
__tablename__ = 'edit_note_change'
__table_args__ = (
Index('edit_note_change_idx_edit_note', 'edit_note'),
{'schema': mbdata.config.schemas.get('musicbrainz', 'musicbrainz')}
)

id = Column(Integer, primary_key=True)
status = Column(Enum('deleted', 'edited', name='EDIT_NOTE_STATUS', schema=mbdata.config.schemas.get('musicbrainz', 'musicbrainz')))
edit_note_id = Column('edit_note', Integer, ForeignKey(apply_schema('edit_note.id', 'musicbrainz'), name='edit_note_change_fk_edit_note'), nullable=False)
change_editor_id = Column('change_editor', Integer, ForeignKey(apply_schema('editor.id', 'musicbrainz'), name='edit_note_change_fk_change_editor'), nullable=False)
change_time = Column(DateTime(timezone=True), server_default=sql.func.now())
old_note = Column(String, nullable=False)
new_note = Column(String, nullable=False)
reason = Column(String, nullable=False, default='', server_default=sql.text("''"))

edit_note = relationship('EditNote', foreign_keys=[edit_note_id], innerjoin=True)
change_editor = relationship('Editor', foreign_keys=[change_editor_id], innerjoin=True)


class EditNoteRecipient(Base):
__tablename__ = 'edit_note_recipient'
__table_args__ = (
Expand Down Expand Up @@ -6526,7 +6545,6 @@ class LinkType(Base):
link_phrase = Column(String(255), nullable=False)
reverse_link_phrase = Column(String(255), nullable=False)
long_link_phrase = Column(String(255), nullable=False)
priority = Column(Integer, nullable=False, default=0, server_default=sql.text('0'))
last_updated = Column(DateTime(timezone=True), server_default=sql.func.now())
is_deprecated = Column(Boolean, nullable=False, default=False, server_default=sql.false())
has_dates = Column(Boolean, nullable=False, default=True, server_default=sql.true())
Expand Down Expand Up @@ -6673,6 +6691,22 @@ class EditorCollectionEvent(Base):
event = relationship('Event', foreign_keys=[event_id], innerjoin=True)


class EditorCollectionGenre(Base):
__tablename__ = 'editor_collection_genre'
__table_args__ = (
{'schema': mbdata.config.schemas.get('musicbrainz', 'musicbrainz')}
)

collection_id = Column('collection', Integer, ForeignKey(apply_schema('editor_collection.id', 'musicbrainz'), name='editor_collection_genre_fk_collection'), nullable=False, primary_key=True)
genre_id = Column('genre', Integer, ForeignKey(apply_schema('genre.id', 'musicbrainz'), name='editor_collection_genre_fk_genre'), nullable=False, primary_key=True)
added = Column(DateTime(timezone=True), server_default=sql.func.now())
position = Column(Integer, nullable=False, default=0, server_default=sql.text('0'))
comment = Column(String, nullable=False, default='', server_default=sql.text("''"))

collection = relationship('EditorCollection', foreign_keys=[collection_id], innerjoin=True)
genre = relationship('Genre', foreign_keys=[genre_id], innerjoin=True)


class EditorCollectionInstrument(Base):
__tablename__ = 'editor_collection_instrument'
__table_args__ = (
Expand Down Expand Up @@ -6841,59 +6875,6 @@ class EditorOauthToken(Base):
application = relationship('Application', foreign_keys=[application_id], innerjoin=True)


class EditorWatchPreferences(Base):
__tablename__ = 'editor_watch_preferences'
__table_args__ = (
{'schema': mbdata.config.schemas.get('musicbrainz', 'musicbrainz')}
)

editor_id = Column('editor', Integer, ForeignKey(apply_schema('editor.id', 'musicbrainz'), name='editor_watch_preferences_fk_editor', ondelete='CASCADE'), nullable=False, primary_key=True)
notify_via_email = Column(Boolean, nullable=False, default=True, server_default=sql.true())
notification_timeframe = Column(Interval, nullable=False, default='1 week', server_default=sql.text("'1 week'"))
last_checked = Column(DateTime(timezone=True), nullable=False, server_default=sql.func.now())

editor = relationship('Editor', foreign_keys=[editor_id], innerjoin=True)


class EditorWatchArtist(Base):
__tablename__ = 'editor_watch_artist'
__table_args__ = (
{'schema': mbdata.config.schemas.get('musicbrainz', 'musicbrainz')}
)

artist_id = Column('artist', Integer, ForeignKey(apply_schema('artist.id', 'musicbrainz'), name='editor_watch_artist_fk_artist', ondelete='CASCADE'), nullable=False, primary_key=True)
editor_id = Column('editor', Integer, ForeignKey(apply_schema('editor.id', 'musicbrainz'), name='editor_watch_artist_fk_editor', ondelete='CASCADE'), nullable=False, primary_key=True)

artist = relationship('Artist', foreign_keys=[artist_id], innerjoin=True)
editor = relationship('Editor', foreign_keys=[editor_id], innerjoin=True)


class EditorWatchReleaseGroupType(Base):
__tablename__ = 'editor_watch_release_group_type'
__table_args__ = (
{'schema': mbdata.config.schemas.get('musicbrainz', 'musicbrainz')}
)

editor_id = Column('editor', Integer, ForeignKey(apply_schema('editor.id', 'musicbrainz'), name='editor_watch_release_group_type_fk_editor', ondelete='CASCADE'), nullable=False, primary_key=True)
release_group_type_id = Column('release_group_type', Integer, ForeignKey(apply_schema('release_group_primary_type.id', 'musicbrainz'), name='editor_watch_release_group_type_fk_release_group_type'), nullable=False, primary_key=True)

editor = relationship('Editor', foreign_keys=[editor_id], innerjoin=True)
release_group_type = relationship('ReleaseGroupPrimaryType', foreign_keys=[release_group_type_id], innerjoin=True)


class EditorWatchReleaseStatus(Base):
__tablename__ = 'editor_watch_release_status'
__table_args__ = (
{'schema': mbdata.config.schemas.get('musicbrainz', 'musicbrainz')}
)

editor_id = Column('editor', Integer, ForeignKey(apply_schema('editor.id', 'musicbrainz'), name='editor_watch_release_status_fk_editor', ondelete='CASCADE'), nullable=False, primary_key=True)
release_status_id = Column('release_status', Integer, ForeignKey(apply_schema('release_status.id', 'musicbrainz'), name='editor_watch_release_status_fk_release_status'), nullable=False, primary_key=True)

editor = relationship('Editor', foreign_keys=[editor_id], innerjoin=True)
release_status = relationship('ReleaseStatus', foreign_keys=[release_status_id], innerjoin=True)


class Medium(Base):
__tablename__ = 'medium'
__table_args__ = (
Expand Down Expand Up @@ -8573,6 +8554,18 @@ class MediumIndex(Base):
medium = relationship('Medium', foreign_keys=[medium_id])


class UnreferencedRowLog(Base):
__tablename__ = 'unreferenced_row_log'
__table_args__ = (
Index('unreferenced_row_log_idx_inserted', 'inserted'),
{'schema': mbdata.config.schemas.get('musicbrainz', 'musicbrainz')}
)

table_name = Column(String, nullable=False, primary_key=True)
row_id = Column(Integer, nullable=False, primary_key=True)
inserted = Column(DateTime(timezone=True), server_default=sql.func.now())


class URL(Base):
__tablename__ = 'url'
__table_args__ = (
Expand Down
5 changes: 3 additions & 2 deletions mbdata/sql/CreateConstraints.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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'
)
Expand Down Expand Up @@ -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)),
Expand Down
60 changes: 20 additions & 40 deletions mbdata/sql/CreateFKConstraints.sql
Original file line number Diff line number Diff line change
Expand Up @@ -500,6 +500,16 @@ ALTER TABLE edit_note
FOREIGN KEY (edit)
REFERENCES edit(id);

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

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

ALTER TABLE edit_note_recipient
ADD CONSTRAINT edit_note_recipient_fk_recipient
FOREIGN KEY (recipient)
Expand Down Expand Up @@ -657,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)
Expand Down Expand Up @@ -877,46 +897,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)
Expand Down
43 changes: 23 additions & 20 deletions mbdata/sql/CreateFunctions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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';
Expand Down Expand Up @@ -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))
Expand Down Expand Up @@ -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;
Expand Down Expand Up @@ -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;

Expand Down
6 changes: 5 additions & 1 deletion mbdata/sql/CreateIndexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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)
);

Expand All @@ -170,6 +170,8 @@ CREATE INDEX edit_url_idx ON edit_url (url);
CREATE INDEX edit_note_idx_edit ON edit_note (edit);
CREATE INDEX edit_note_idx_editor ON edit_note (editor);

CREATE INDEX edit_note_change_idx_edit_note ON edit_note_change (edit_note);

CREATE INDEX edit_note_recipient_idx_recipient ON edit_note_recipient (recipient);

CREATE UNIQUE INDEX event_idx_gid ON event (gid);
Expand Down Expand Up @@ -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);

Expand Down
7 changes: 3 additions & 4 deletions mbdata/sql/CreatePrimaryKeys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -54,6 +54,7 @@ ALTER TABLE edit_instrument ADD CONSTRAINT edit_instrument_pkey PRIMARY KEY (edi
ALTER TABLE edit_label ADD CONSTRAINT edit_label_pkey PRIMARY KEY (edit, label);
ALTER TABLE edit_mood ADD CONSTRAINT edit_mood_pkey PRIMARY KEY (edit, mood);
ALTER TABLE edit_note ADD CONSTRAINT edit_note_pkey PRIMARY KEY (id);
ALTER TABLE edit_note_change ADD CONSTRAINT edit_note_change_pkey PRIMARY KEY (id);
ALTER TABLE edit_note_recipient ADD CONSTRAINT edit_note_recipient_pkey PRIMARY KEY (recipient, edit_note);
ALTER TABLE edit_place ADD CONSTRAINT edit_place_pkey PRIMARY KEY (edit, place);
ALTER TABLE edit_recording ADD CONSTRAINT edit_recording_pkey PRIMARY KEY (edit, recording);
Expand All @@ -69,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);
Expand All @@ -90,10 +92,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);
Expand Down Expand Up @@ -350,6 +348,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);
Expand Down
Loading

0 comments on commit 37d507a

Please sign in to comment.