Skip to content

Commit

Permalink
Update SQL scripts
Browse files Browse the repository at this point in the history
  • Loading branch information
lalinsky committed May 15, 2012
1 parent cf7dc6e commit 4c8b111
Show file tree
Hide file tree
Showing 62 changed files with 1,727 additions and 89 deletions.
84 changes: 82 additions & 2 deletions sql/CreateFKConstraints.sql
Expand Up @@ -41,6 +41,16 @@ ALTER TABLE artist_alias
FOREIGN KEY (name)
REFERENCES artist_name(id);

ALTER TABLE artist_alias
ADD CONSTRAINT artist_alias_fk_sort_name
FOREIGN KEY (sort_name)
REFERENCES artist_name(id);

ALTER TABLE artist_alias
ADD CONSTRAINT artist_alias_fk_type
FOREIGN KEY (type)
REFERENCES artist_alias_type(id);

ALTER TABLE artist_annotation
ADD CONSTRAINT artist_annotation_fk_artist
FOREIGN KEY (artist)
Expand Down Expand Up @@ -78,6 +88,11 @@ ALTER TABLE artist_gid_redirect
FOREIGN KEY (new_id)
REFERENCES artist(id);

ALTER TABLE artist_ipi
ADD CONSTRAINT artist_ipi_fk_artist
FOREIGN KEY (artist)
REFERENCES artist(id);

ALTER TABLE artist_meta
ADD CONSTRAINT artist_meta_fk_id
FOREIGN KEY (id)
Expand Down Expand Up @@ -246,6 +261,16 @@ ALTER TABLE edit_work
REFERENCES work(id)
ON DELETE CASCADE;

ALTER TABLE editor
ADD CONSTRAINT editor_fk_gender
FOREIGN KEY (gender)
REFERENCES gender(id);

ALTER TABLE editor
ADD CONSTRAINT editor_fk_country
FOREIGN KEY (country)
REFERENCES country(id);

ALTER TABLE editor_collection
ADD CONSTRAINT editor_collection_fk_editor
FOREIGN KEY (editor)
Expand All @@ -261,6 +286,16 @@ ALTER TABLE editor_collection_release
FOREIGN KEY (release)
REFERENCES release(id);

ALTER TABLE editor_language
ADD CONSTRAINT editor_language_fk_editor
FOREIGN KEY (editor)
REFERENCES editor(id);

ALTER TABLE editor_language
ADD CONSTRAINT editor_language_fk_language
FOREIGN KEY (language)
REFERENCES language(id);

ALTER TABLE editor_preference
ADD CONSTRAINT editor_preference_fk_editor
FOREIGN KEY (editor)
Expand Down Expand Up @@ -313,7 +348,7 @@ ALTER TABLE editor_watch_release_group_type
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_type(id);
REFERENCES release_group_primary_type(id);

ALTER TABLE editor_watch_release_status
ADD CONSTRAINT editor_watch_release_status_fk_editor
Expand All @@ -331,6 +366,11 @@ ALTER TABLE isrc
FOREIGN KEY (recording)
REFERENCES recording(id);

ALTER TABLE iswc
ADD CONSTRAINT iswc_fk_work
FOREIGN KEY (work)
REFERENCES work(id);

ALTER TABLE l_artist_artist
ADD CONSTRAINT l_artist_artist_fk_link
FOREIGN KEY (link)
Expand Down Expand Up @@ -781,6 +821,16 @@ ALTER TABLE label_alias
FOREIGN KEY (name)
REFERENCES label_name(id);

ALTER TABLE label_alias
ADD CONSTRAINT label_alias_fk_sort_name
FOREIGN KEY (sort_name)
REFERENCES label_name(id);

ALTER TABLE label_alias
ADD CONSTRAINT label_alias_fk_type
FOREIGN KEY (type)
REFERENCES label_alias_type(id);

ALTER TABLE label_annotation
ADD CONSTRAINT label_annotation_fk_label
FOREIGN KEY (label)
Expand All @@ -796,6 +846,11 @@ ALTER TABLE label_gid_redirect
FOREIGN KEY (new_id)
REFERENCES label(id);

ALTER TABLE label_ipi
ADD CONSTRAINT label_ipi_fk_label
FOREIGN KEY (label)
REFERENCES label(id);

ALTER TABLE label_meta
ADD CONSTRAINT label_meta_fk_id
FOREIGN KEY (id)
Expand Down Expand Up @@ -1062,7 +1117,7 @@ ALTER TABLE release_group
ALTER TABLE release_group
ADD CONSTRAINT release_group_fk_type
FOREIGN KEY (type)
REFERENCES release_group_type(id);
REFERENCES release_group_primary_type(id);

ALTER TABLE release_group_annotation
ADD CONSTRAINT release_group_annotation_fk_release_group
Expand Down Expand Up @@ -1095,6 +1150,16 @@ ALTER TABLE release_group_rating_raw
FOREIGN KEY (editor)
REFERENCES editor(id);

ALTER TABLE release_group_secondary_type_join
ADD CONSTRAINT release_group_secondary_type_join_fk_release_group
FOREIGN KEY (release_group)
REFERENCES release_group(id);

ALTER TABLE release_group_secondary_type_join
ADD CONSTRAINT release_group_secondary_type_join_fk_secondary_type
FOREIGN KEY (secondary_type)
REFERENCES release_group_secondary_type(id);

ALTER TABLE release_group_tag
ADD CONSTRAINT release_group_tag_fk_release_group
FOREIGN KEY (release_group)
Expand Down Expand Up @@ -1231,6 +1296,11 @@ ALTER TABLE work
FOREIGN KEY (type)
REFERENCES work_type(id);

ALTER TABLE work
ADD CONSTRAINT work_fk_language
FOREIGN KEY (language)
REFERENCES language (id);

ALTER TABLE work_alias
ADD CONSTRAINT work_alias_fk_work
FOREIGN KEY (work)
Expand All @@ -1241,6 +1311,16 @@ ALTER TABLE work_alias
FOREIGN KEY (name)
REFERENCES work_name(id);

ALTER TABLE work_alias
ADD CONSTRAINT work_alias_fk_sort_name
FOREIGN KEY (sort_name)
REFERENCES work_name(id);

ALTER TABLE work_alias
ADD CONSTRAINT work_alias_fk_type
FOREIGN KEY (type)
REFERENCES work_alias_type(id);

ALTER TABLE work_annotation
ADD CONSTRAINT work_annotation_fk_work
FOREIGN KEY (work)
Expand Down
44 changes: 42 additions & 2 deletions sql/CreateFunctions.sql
Expand Up @@ -706,7 +706,47 @@ BEGIN
END;
$$ LANGUAGE 'plpgsql';

COMMIT;
-- vi: set ts=4 sw=4 et :
CREATE OR REPLACE FUNCTION unique_primary()
RETURNS trigger AS $$
BEGIN
IF NEW.primary_for_locale THEN
EXECUTE 'UPDATE ' || quote_ident(TG_ARGV[0]) || ' SET primary_for_locale = FALSE WHERE locale = $1'
USING NEW.locale;
END IF;
RETURN NEW;
END;
$$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION simplify_search_hints()
RETURNS trigger AS $$
BEGIN
IF NEW.type::int = TG_ARGV[0]::int THEN
NEW.sort_name := NEW.name;
NEW.begin_date_year := NULL;
NEW.begin_date_month := NULL;
NEW.begin_date_day := NULL;
NEW.end_date_year := NULL;
NEW.end_date_month := NULL;
NEW.end_date_day := NULL;
NEW.end_date_day := NULL;
NEW.locale := NULL;
END IF;
RETURN NEW;
END;
$$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION end_date_implies_ended()
RETURNS trigger AS $$
BEGIN
IF NEW.end_date_year IS NOT NULL OR
NEW.end_date_month IS NOT NULL OR
NEW.end_date_day IS NOT NULL
THEN
NEW.ended = TRUE;
END IF;
RETURN NEW;
END;
$$ LANGUAGE 'plpgsql';

COMMIT;
-- vi: set ts=4 sw=4 et :
19 changes: 11 additions & 8 deletions sql/CreateIndexes.sql
Expand Up @@ -4,10 +4,9 @@ BEGIN;
CREATE UNIQUE INDEX artist_idx_gid ON artist (gid);
CREATE INDEX artist_idx_name ON artist (name);
CREATE INDEX artist_idx_sort_name ON artist (sort_name);
CREATE INDEX artist_idx_ipi_code ON artist (ipi_code);

CREATE INDEX artist_alias_idx_artist ON artist_alias (artist);
CREATE UNIQUE INDEX artist_alias_idx_locale_artist ON artist_alias (artist, locale);
CREATE UNIQUE INDEX artist_alias_idx_primary ON artist_alias (artist, locale) WHERE primary_for_locale = TRUE AND locale IS NOT NULL;

CREATE INDEX artist_credit_name_idx_artist ON artist_credit_name (artist);

Expand All @@ -31,6 +30,7 @@ CREATE UNIQUE INDEX cdtoc_raw_toc ON cdtoc_raw (track_count, leadout_offset, tra
CREATE UNIQUE INDEX country_idx_iso_code ON country (iso_code);

CREATE UNIQUE INDEX editor_idx_name ON editor (LOWER(name));
CREATE INDEX editor_language_idx_language ON editor_language (language);

CREATE UNIQUE INDEX editor_preference_idx_editor_name ON editor_preference (editor, name);

Expand Down Expand Up @@ -65,6 +65,9 @@ CREATE INDEX isrc_idx_isrc ON isrc (isrc);
CREATE INDEX isrc_idx_recording ON isrc (recording);
CREATE UNIQUE INDEX isrc_idx_isrc_recording ON isrc (isrc, recording);

CREATE INDEX iswc_idx_work ON iswc (work);
CREATE UNIQUE INDEX iswc_idx_iswc ON iswc (iswc, work);

CREATE UNIQUE INDEX l_artist_artist_idx_uniq ON l_artist_artist (entity0, entity1, link);
CREATE UNIQUE INDEX l_artist_label_idx_uniq ON l_artist_label (entity0, entity1, link);
CREATE UNIQUE INDEX l_artist_recording_idx_uniq ON l_artist_recording (entity0, entity1, link);
Expand Down Expand Up @@ -143,10 +146,9 @@ CREATE INDEX link_idx_type_attr ON link (link_type, attribute_count);
CREATE UNIQUE INDEX label_idx_gid ON label (gid);
CREATE INDEX label_idx_name ON label (name);
CREATE INDEX label_idx_sort_name ON label (sort_name);
CREATE INDEX label_idx_ipi_code ON label (ipi_code);

CREATE INDEX label_alias_idx_label ON label_alias (label);
CREATE UNIQUE INDEX label_alias_idx_locale_label ON label_alias (label, locale);
CREATE UNIQUE INDEX label_alias_idx_primary ON label_alias (label, locale) WHERE primary_for_locale = TRUE AND locale IS NOT NULL;

CREATE UNIQUE INDEX label_name_idx_name ON label_name (name);
CREATE INDEX label_name_idx_page ON label_name (page_index(name));
Expand All @@ -162,9 +164,10 @@ CREATE INDEX label_rating_raw_idx_label ON label_rating_raw (label);
CREATE INDEX label_rating_raw_idx_editor ON label_rating_raw (editor);


CREATE UNIQUE INDEX language_idx_iso_code_3b ON language (iso_code_3b);
CREATE UNIQUE INDEX language_idx_iso_code_3t ON language (iso_code_3t);
CREATE UNIQUE INDEX language_idx_iso_code_2 ON language (iso_code_2);
CREATE UNIQUE INDEX language_idx_iso_code_2b ON language (iso_code_2b);
CREATE UNIQUE INDEX language_idx_iso_code_2t ON language (iso_code_2t);
CREATE UNIQUE INDEX language_idx_iso_code_1 ON language (iso_code_1);
CREATE UNIQUE INDEX language_idx_iso_code_3 ON language (iso_code_3);

CREATE UNIQUE INDEX editor_collection_idx_gid ON editor_collection (gid);
CREATE INDEX editor_collection_idx_name ON editor_collection (name);
Expand Down Expand Up @@ -265,7 +268,7 @@ CREATE INDEX work_idx_name ON work (name);
CREATE INDEX work_idx_artist_credit ON work (artist_credit);

CREATE INDEX work_alias_idx_work ON work_alias (work);
CREATE UNIQUE INDEX work_alias_idx_locale_work ON work_alias (work, locale);
CREATE UNIQUE INDEX work_alias_idx_primary ON work_alias (work, locale) WHERE primary_for_locale = TRUE AND locale IS NOT NULL;

CREATE UNIQUE INDEX work_name_idx_name ON work_name (name);
CREATE INDEX work_name_idx_page ON work_name (page_index(name));
Expand Down
2 changes: 0 additions & 2 deletions sql/CreatePLPerl.sql
@@ -1,7 +1,5 @@
BEGIN;

CREATE LANGUAGE plperlu;

CREATE OR REPLACE FUNCTION extract_path_value(text, text)
RETURNS TEXT
AS $$
Expand Down
12 changes: 11 additions & 1 deletion sql/CreatePrimaryKeys.sql
Expand Up @@ -4,10 +4,12 @@
ALTER TABLE annotation ADD CONSTRAINT annotation_pkey PRIMARY KEY (id);
ALTER TABLE artist ADD CONSTRAINT artist_pkey PRIMARY KEY (id);
ALTER TABLE artist_alias ADD CONSTRAINT artist_alias_pkey PRIMARY KEY (id);
ALTER TABLE artist_alias_type ADD CONSTRAINT artist_alias_type_pkey PRIMARY KEY (id);
ALTER TABLE artist_annotation ADD CONSTRAINT artist_annotation_pkey PRIMARY KEY (artist, annotation);
ALTER TABLE artist_credit ADD CONSTRAINT artist_credit_pkey PRIMARY KEY (id);
ALTER TABLE artist_credit_name ADD CONSTRAINT artist_credit_name_pkey PRIMARY KEY (artist_credit, position);
ALTER TABLE artist_gid_redirect ADD CONSTRAINT artist_gid_redirect_pkey PRIMARY KEY (gid);
ALTER TABLE artist_ipi ADD CONSTRAINT artist_ipi_pkey PRIMARY KEY (artist, ipi);
ALTER TABLE artist_meta ADD CONSTRAINT artist_meta_pkey PRIMARY KEY (id);
ALTER TABLE artist_name ADD CONSTRAINT artist_name_pkey PRIMARY KEY (id);
ALTER TABLE artist_rating_raw ADD CONSTRAINT artist_rating_raw_pkey PRIMARY KEY (artist, editor);
Expand All @@ -32,6 +34,7 @@ ALTER TABLE edit_work ADD CONSTRAINT edit_work_pkey PRIMARY KEY (edit, work);
ALTER TABLE editor ADD CONSTRAINT editor_pkey PRIMARY KEY (id);
ALTER TABLE editor_collection ADD CONSTRAINT editor_collection_pkey PRIMARY KEY (id);
ALTER TABLE editor_collection_release ADD CONSTRAINT editor_collection_release_pkey PRIMARY KEY (collection, release);
ALTER TABLE editor_language ADD CONSTRAINT editor_language_pkey PRIMARY KEY (editor, language);
ALTER TABLE editor_preference ADD CONSTRAINT editor_preference_pkey PRIMARY KEY (id);
ALTER TABLE editor_subscribe_artist ADD CONSTRAINT editor_subscribe_artist_pkey PRIMARY KEY (id);
ALTER TABLE editor_subscribe_editor ADD CONSTRAINT editor_subscribe_editor_pkey PRIMARY KEY (id);
Expand All @@ -42,6 +45,7 @@ ALTER TABLE editor_watch_release_group_type ADD CONSTRAINT editor_watch_release_
ALTER TABLE editor_watch_release_status ADD CONSTRAINT editor_watch_release_status_pkey PRIMARY KEY (editor, release_status);
ALTER TABLE gender ADD CONSTRAINT gender_pkey PRIMARY KEY (id);
ALTER TABLE isrc ADD CONSTRAINT isrc_pkey PRIMARY KEY (id);
ALTER TABLE iswc ADD CONSTRAINT iswc_pkey PRIMARY KEY (id);
ALTER TABLE l_artist_artist ADD CONSTRAINT l_artist_artist_pkey PRIMARY KEY (id);
ALTER TABLE l_artist_label ADD CONSTRAINT l_artist_label_pkey PRIMARY KEY (id);
ALTER TABLE l_artist_recording ADD CONSTRAINT l_artist_recording_pkey PRIMARY KEY (id);
Expand Down Expand Up @@ -72,8 +76,10 @@ ALTER TABLE l_url_work ADD CONSTRAINT l_url_work_pkey PRIMARY KEY (id);
ALTER TABLE l_work_work ADD CONSTRAINT l_work_work_pkey PRIMARY KEY (id);
ALTER TABLE label ADD CONSTRAINT label_pkey PRIMARY KEY (id);
ALTER TABLE label_alias ADD CONSTRAINT label_alias_pkey PRIMARY KEY (id);
ALTER TABLE label_alias_type ADD CONSTRAINT label_alias_type_pkey PRIMARY KEY (id);
ALTER TABLE label_annotation ADD CONSTRAINT label_annotation_pkey PRIMARY KEY (label, annotation);
ALTER TABLE label_gid_redirect ADD CONSTRAINT label_gid_redirect_pkey PRIMARY KEY (gid);
ALTER TABLE label_ipi ADD CONSTRAINT label_ipi_pkey PRIMARY KEY (label, ipi);
ALTER TABLE label_meta ADD CONSTRAINT label_meta_pkey PRIMARY KEY (id);
ALTER TABLE label_name ADD CONSTRAINT label_name_pkey PRIMARY KEY (id);
ALTER TABLE label_rating_raw ADD CONSTRAINT label_rating_raw_pkey PRIMARY KEY (label, editor);
Expand Down Expand Up @@ -106,10 +112,12 @@ ALTER TABLE release_group ADD CONSTRAINT release_group_pkey PRIMARY KEY (id);
ALTER TABLE release_group_annotation ADD CONSTRAINT release_group_annotation_pkey PRIMARY KEY (release_group, annotation);
ALTER TABLE release_group_gid_redirect ADD CONSTRAINT release_group_gid_redirect_pkey PRIMARY KEY (gid);
ALTER TABLE release_group_meta ADD CONSTRAINT release_group_meta_pkey PRIMARY KEY (id);
ALTER TABLE release_group_primary_type ADD CONSTRAINT release_group_primary_type_pkey PRIMARY KEY (id);
ALTER TABLE release_group_rating_raw ADD CONSTRAINT release_group_rating_raw_pkey PRIMARY KEY (release_group, editor);
ALTER TABLE release_group_secondary_type ADD CONSTRAINT release_group_secondary_type_pkey PRIMARY KEY (id);
ALTER TABLE release_group_secondary_type_join ADD CONSTRAINT release_group_secondary_type_join_pkey PRIMARY KEY (release_group, secondary_type);
ALTER TABLE release_group_tag ADD CONSTRAINT release_group_tag_pkey PRIMARY KEY (release_group, tag);
ALTER TABLE release_group_tag_raw ADD CONSTRAINT release_group_tag_raw_pkey PRIMARY KEY (release_group, editor, tag);
ALTER TABLE release_group_type ADD CONSTRAINT release_group_type_pkey PRIMARY KEY (id);
ALTER TABLE release_label ADD CONSTRAINT release_label_pkey PRIMARY KEY (id);
ALTER TABLE release_meta ADD CONSTRAINT release_meta_pkey PRIMARY KEY (id);
ALTER TABLE release_name ADD CONSTRAINT release_name_pkey PRIMARY KEY (id);
Expand All @@ -122,6 +130,7 @@ ALTER TABLE replication_control ADD CONSTRAINT replication_control_pkey PRIMARY
ALTER TABLE script ADD CONSTRAINT script_pkey PRIMARY KEY (id);
ALTER TABLE script_language ADD CONSTRAINT script_language_pkey PRIMARY KEY (id);
ALTER TABLE statistic ADD CONSTRAINT statistic_pkey PRIMARY KEY (id);
ALTER TABLE statistic_event ADD CONSTRAINT statistic_event_pkey PRIMARY KEY (date);
ALTER TABLE tag ADD CONSTRAINT tag_pkey PRIMARY KEY (id);
ALTER TABLE tag_relation ADD CONSTRAINT tag_relation_pkey PRIMARY KEY (tag1, tag2);
ALTER TABLE track ADD CONSTRAINT track_pkey PRIMARY KEY (id);
Expand All @@ -134,6 +143,7 @@ ALTER TABLE url_gid_redirect ADD CONSTRAINT url_gid_redirect_pkey PRIMARY KEY (g
ALTER TABLE vote ADD CONSTRAINT vote_pkey PRIMARY KEY (id);
ALTER TABLE work ADD CONSTRAINT work_pkey PRIMARY KEY (id);
ALTER TABLE work_alias ADD CONSTRAINT work_alias_pkey PRIMARY KEY (id);
ALTER TABLE work_alias_type ADD CONSTRAINT work_alias_type_pkey PRIMARY KEY (id);
ALTER TABLE work_annotation ADD CONSTRAINT work_annotation_pkey PRIMARY KEY (work, annotation);
ALTER TABLE work_gid_redirect ADD CONSTRAINT work_gid_redirect_pkey PRIMARY KEY (gid);
ALTER TABLE work_meta ADD CONSTRAINT work_meta_pkey PRIMARY KEY (id);
Expand Down

0 comments on commit 4c8b111

Please sign in to comment.