Skip to content

Commit

Permalink
Merge branch 'schema-change-2016-q2'
Browse files Browse the repository at this point in the history
* schema-change-2016-q2: (88 commits)
  Cast text to jsonb
  Fix DROP FUNCTION syntax
  Run CompileSchemaScripts
  Move MBS-8720 FKs/triggers to standalone-only script
  Fix CREATE FUNCTION ... LANGUAGE 'C' for PG 9.2+
  Increment DB_SCHEMA_SEQUENCE in DBDefs.pm.sample
  Update the minimum requirements in INSTALL.md
  Run CompileSchemaScripts
  Split MockEdit class from EditQueue tests into two
  Missing DELETE FROM vote
  Allow mock edits to override yes_votes/no_votes
  Fix incorrect variable reference
  Filter out superseded votes in yes_votes/no_votes
  Remove data column from more edit tests
  Recluster the edit table
  Remove all traces of materialized edit/editor columns
  MBS-8719: Drop unused materialized columns
  MBS-8719: Stop materializing user edit counts
  MBS-8719: Stop materializing yes/no vote counts
  Compute various edit counts in one go
  ...
  • Loading branch information
mwiencek committed May 23, 2016
2 parents da70889 + c95cad9 commit 30824f0
Show file tree
Hide file tree
Showing 214 changed files with 3,617 additions and 1,111 deletions.
26 changes: 11 additions & 15 deletions INSTALL.md
Original file line number Diff line number Diff line change
Expand Up @@ -18,26 +18,29 @@ Prerequisites
some hoops. If you are running Windows we recommend you set up a Ubuntu virtual
machine.

**This document will assume you are using Ubuntu for its instructions.**
**This document will assume you are using Ubuntu (at least 14.04) for its
instructions.**

2. Perl (at least version 5.10.1)
2. Perl (at least version 5.18.2)

Perl comes bundled with most Linux operating systems, you can check your
installed version of Perl with:

perl -v

3. PostgreSQL (at least version 9.1)
3. PostgreSQL (at least version 9.5)

PostgreSQL is required, along with its development libraries. To install
using packages run the following, replacing 9.x with the latest version.
If needed, packages of all supported PostgreSQL versions for various Ubuntu
releases are available from the [PostgreSQL apt repository](http://www.postgresql.org/download/linux/ubuntu/).

sudo apt-get install postgresql-9.x postgresql-server-dev-9.x postgresql-contrib-9.x postgresql-plperl-9.x
sudo apt-get install postgresql-9.x postgresql-server-dev-9.x postgresql-contrib-9.x

Alternatively, you may compile PostgreSQL from source, but then make sure to
also compile the cube extension found in contrib/cube. The database import
script will take care of installing that extension into the database when it
creates the database for you.
also compile the cube and earthdistance extensions found in the contrib
directory. The database import script will take care of installing those
extensions into the database when it creates the database for you.

4. Git

Expand Down Expand Up @@ -258,14 +261,7 @@ Creating the database
Note that a running PostgreSQL will pick up changes to configuration files
only when being told so via a `HUP` signal.

3. Install a Perl module

One PL/Perl database function requires the JSON::XS Perl module. Install it
like so:

sudo apt-get install libjson-xs-perl

4. Create the database
3. Create the database

You have two options when it comes to the database. You can either opt for a
clean database with just the schema (useful for developers with limited disk
Expand Down
1 change: 1 addition & 0 deletions admin/CompileSchemaScripts.pl
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,7 @@
$data .= <<EOSQL;
\\set ON_ERROR_STOP 1
BEGIN;
SET search_path = musicbrainz, public;
EOSQL
for my $script (@$scripts) {
my @script_data = read_file("$FindBin::Bin/sql/updates/$script");
Expand Down
10 changes: 6 additions & 4 deletions admin/ExportAllTables
Original file line number Diff line number Diff line change
Expand Up @@ -47,6 +47,11 @@ my @replication_tables = qw(
);

my @group_core = qw(
alternative_medium
alternative_medium_track
alternative_release
alternative_release_type
alternative_track
area
area_type
area_alias
Expand Down Expand Up @@ -277,6 +282,7 @@ my @group_edit = qw(
edit_instrument
edit_label
edit_note
edit_note_recipient
edit_place
edit_recording
edit_release
Expand Down Expand Up @@ -523,10 +529,6 @@ if (grep { $_ eq "editor_sanitised" } @tables)
member_since,
email_confirm_date,
now() AS last_login_date,
edits_accepted,
edits_rejected,
auto_edits_accepted,
edits_failed,
last_updated,
NULL AS birth_date,
NULL AS gender,
Expand Down
17 changes: 2 additions & 15 deletions admin/InitDb.pl
Original file line number Diff line number Diff line change
Expand Up @@ -119,17 +119,9 @@ sub RunSQLScript
die "Error during $file" if ($? >> 8);
}

sub HasPLPerlSupport
{
my $mb = Databases->get_connection('MAINTENANCE');
my $mb_no_schema = $mb->meta->clone_object($mb, database => $mb->database->meta->clone_object($mb->database));
my $sql = Sql->new( $mb_no_schema->conn );
return $sql->select_single_value('SELECT TRUE FROM pg_language WHERE lanname = ?', 'plperlu');
}

sub HasEditData
{
my $mb = Databases->get_connection('MAINTENANCE');
my $mb = Databases->get_connection($databaseName);
my $sql = Sql->new( $mb->conn );
return $sql->select_single_value('SELECT TRUE FROM edit LIMIT 1');
}
Expand Down Expand Up @@ -159,7 +151,7 @@ sub CreateReplicationFunction
$sql->auto_commit;
$sql->do(
"CREATE FUNCTION \"recordchange\" () RETURNS trigger
AS ?, 'recordchange' LANGUAGE 'C'",
AS ?, 'recordchange' LANGUAGE C",
$path_to_pending_so,
);
}
Expand Down Expand Up @@ -247,8 +239,6 @@ sub Create
$ENV{"PGPASSWORD"} = $sys_db->password;
system "createlang", @opts, "plpgsql";
print "\nFailed to create language plpgsql -- it's likely to be already installed, continuing.\n" if ($? >> 8);
system "createlang", @opts, "plperlu";
print "\nFailed to create language plperlu -- it's likely to be already installed, continuing.\n" if ($? >> 8);

# Set the default search path for the READWRITE and READONLY users
my $search_path = "musicbrainz, public";
Expand Down Expand Up @@ -326,9 +316,6 @@ sub CreateRelations
RunSQLScript($DB, "CreateFunctions.sql", "Creating functions ...");
RunSQLScript($DB, "caa/CreateFunctions.sql", "Creating CAA functions ...");

RunSQLScript($SYSMB, "CreatePLPerl.sql", "Creating system functions ...")
if HasPLPerlSupport();

RunSQLScript($DB, "CreateIndexes.sql", "Creating indexes ...");
RunSQLScript($DB, "caa/CreateIndexes.sql", "Creating CAA indexes ...");
RunSQLScript($DB, "sitemaps/CreateIndexes.sql", "Creating sitemaps indexes ...");
Expand Down
91 changes: 88 additions & 3 deletions admin/sql/CreateFKConstraints.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,66 @@
-- Automatically generated, do not edit.
\set ON_ERROR_STOP 1

ALTER TABLE alternative_medium
ADD CONSTRAINT alternative_medium_fk_medium
FOREIGN KEY (medium)
REFERENCES medium(id);

ALTER TABLE alternative_medium
ADD CONSTRAINT alternative_medium_fk_alternative_release
FOREIGN KEY (alternative_release)
REFERENCES alternative_release(id);

ALTER TABLE alternative_medium_track
ADD CONSTRAINT alternative_medium_track_fk_alternative_medium
FOREIGN KEY (alternative_medium)
REFERENCES alternative_medium(id);

ALTER TABLE alternative_medium_track
ADD CONSTRAINT alternative_medium_track_fk_track
FOREIGN KEY (track)
REFERENCES track(id);

ALTER TABLE alternative_medium_track
ADD CONSTRAINT alternative_medium_track_fk_alternative_track
FOREIGN KEY (alternative_track)
REFERENCES alternative_track(id);

ALTER TABLE alternative_release
ADD CONSTRAINT alternative_release_fk_release
FOREIGN KEY (release)
REFERENCES release(id);

ALTER TABLE alternative_release
ADD CONSTRAINT alternative_release_fk_artist_credit
FOREIGN KEY (artist_credit)
REFERENCES artist_credit(id);

ALTER TABLE alternative_release
ADD CONSTRAINT alternative_release_fk_type
FOREIGN KEY (type)
REFERENCES alternative_release_type(id);

ALTER TABLE alternative_release
ADD CONSTRAINT alternative_release_fk_language
FOREIGN KEY (language)
REFERENCES language(id);

ALTER TABLE alternative_release
ADD CONSTRAINT alternative_release_fk_script
FOREIGN KEY (script)
REFERENCES script(id);

ALTER TABLE alternative_release_type
ADD CONSTRAINT alternative_release_type_fk_parent
FOREIGN KEY (parent)
REFERENCES alternative_release_type(id);

ALTER TABLE alternative_track
ADD CONSTRAINT alternative_track_fk_artist_credit
FOREIGN KEY (artist_credit)
REFERENCES artist_credit(id);

ALTER TABLE annotation
ADD CONSTRAINT annotation_fk_editor
FOREIGN KEY (editor)
Expand Down Expand Up @@ -271,6 +331,11 @@ ALTER TABLE edit_artist
REFERENCES artist(id)
ON DELETE CASCADE;

ALTER TABLE edit_data
ADD CONSTRAINT edit_data_fk_edit
FOREIGN KEY (edit)
REFERENCES edit(id);

ALTER TABLE edit_event
ADD CONSTRAINT edit_event_fk_edit
FOREIGN KEY (edit)
Expand Down Expand Up @@ -314,6 +379,16 @@ ALTER TABLE edit_note
FOREIGN KEY (edit)
REFERENCES edit(id);

ALTER TABLE edit_note_recipient
ADD CONSTRAINT edit_note_recipient_fk_recipient
FOREIGN KEY (recipient)
REFERENCES editor(id);

ALTER TABLE edit_note_recipient
ADD CONSTRAINT edit_note_recipient_fk_edit_note
FOREIGN KEY (edit_note)
REFERENCES edit_note(id);

ALTER TABLE edit_place
ADD CONSTRAINT edit_place_fk_edit
FOREIGN KEY (edit)
Expand Down Expand Up @@ -431,6 +506,16 @@ ALTER TABLE editor_collection_artist
FOREIGN KEY (artist)
REFERENCES artist(id);

ALTER TABLE editor_collection_deleted_entity
ADD CONSTRAINT editor_collection_deleted_entity_fk_collection
FOREIGN KEY (collection)
REFERENCES editor_collection(id);

ALTER TABLE editor_collection_deleted_entity
ADD CONSTRAINT editor_collection_deleted_entity_fk_gid
FOREIGN KEY (gid)
REFERENCES deleted_entity(gid);

ALTER TABLE editor_collection_event
ADD CONSTRAINT editor_collection_event_fk_collection
FOREIGN KEY (collection)
Expand Down Expand Up @@ -574,7 +659,7 @@ ALTER TABLE editor_subscribe_artist_deleted
ALTER TABLE editor_subscribe_artist_deleted
ADD CONSTRAINT editor_subscribe_artist_deleted_fk_gid
FOREIGN KEY (gid)
REFERENCES artist_deletion(gid);
REFERENCES deleted_entity(gid);

ALTER TABLE editor_subscribe_artist_deleted
ADD CONSTRAINT editor_subscribe_artist_deleted_fk_deleted_by
Expand Down Expand Up @@ -619,7 +704,7 @@ ALTER TABLE editor_subscribe_label_deleted
ALTER TABLE editor_subscribe_label_deleted
ADD CONSTRAINT editor_subscribe_label_deleted_fk_gid
FOREIGN KEY (gid)
REFERENCES label_deletion(gid);
REFERENCES deleted_entity(gid);

ALTER TABLE editor_subscribe_label_deleted
ADD CONSTRAINT editor_subscribe_label_deleted_fk_deleted_by
Expand Down Expand Up @@ -649,7 +734,7 @@ ALTER TABLE editor_subscribe_series_deleted
ALTER TABLE editor_subscribe_series_deleted
ADD CONSTRAINT editor_subscribe_series_deleted_fk_gid
FOREIGN KEY (gid)
REFERENCES series_deletion(gid);
REFERENCES deleted_entity(gid);

ALTER TABLE editor_subscribe_series_deleted
ADD CONSTRAINT editor_subscribe_series_deleted_fk_deleted_by
Expand Down
86 changes: 86 additions & 0 deletions admin/sql/CreateFunctions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -386,6 +386,76 @@ RETURNS trigger AS $$
END;
$$ LANGUAGE 'plpgsql';

-----------------------------------------------------------------------
-- alternative tracklist triggers
-----------------------------------------------------------------------

CREATE OR REPLACE FUNCTION inc_nullable_artist_credit(row_id integer) RETURNS void AS $$
BEGIN
IF row_id IS NOT NULL THEN
PERFORM inc_ref_count('artist_credit', row_id, 1);
END IF;
RETURN;
END;
$$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION dec_nullable_artist_credit(row_id integer) RETURNS void AS $$
BEGIN
IF row_id IS NOT NULL THEN
PERFORM dec_ref_count('artist_credit', row_id, 1);
END IF;
RETURN;
END;
$$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION a_ins_alternative_release_or_track() RETURNS trigger AS $$
BEGIN
PERFORM inc_nullable_artist_credit(NEW.artist_credit);
RETURN NULL;
END;
$$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION a_upd_alternative_release_or_track() RETURNS trigger AS $$
BEGIN
IF NEW.artist_credit IS DISTINCT FROM OLD.artist_credit THEN
PERFORM inc_nullable_artist_credit(NEW.artist_credit);
PERFORM dec_nullable_artist_credit(OLD.artist_credit);
END IF;
RETURN NULL;
END;
$$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION a_del_alternative_release_or_track() RETURNS trigger AS $$
BEGIN
PERFORM dec_nullable_artist_credit(OLD.artist_credit);
RETURN NULL;
END;
$$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION a_ins_alternative_medium_track() RETURNS trigger AS $$
BEGIN
PERFORM inc_ref_count('alternative_track', NEW.alternative_track, 1);
RETURN NULL;
END;
$$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION a_upd_alternative_medium_track() RETURNS trigger AS $$
BEGIN
IF NEW.alternative_track IS DISTINCT FROM OLD.alternative_track THEN
PERFORM inc_ref_count('alternative_track', NEW.alternative_track, 1);
PERFORM dec_ref_count('alternative_track', OLD.alternative_track, 1);
END IF;
RETURN NULL;
END;
$$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION a_del_alternative_medium_track() RETURNS trigger AS $$
BEGIN
PERFORM dec_ref_count('alternative_track', OLD.alternative_track, 1);
RETURN NULL;
END;
$$ LANGUAGE 'plpgsql';

-----------------------------------------------------------------------
-- lastupdate triggers
-----------------------------------------------------------------------
Expand Down Expand Up @@ -1079,4 +1149,20 @@ CREATE OR REPLACE FUNCTION track_count_matches_cdtoc(medium, int) RETURNS boolea
$$ LANGUAGE SQL IMMUTABLE;

COMMIT;

-----------------------------------------------------------------------
-- edit_note triggers
-----------------------------------------------------------------------

CREATE OR REPLACE FUNCTION a_ins_edit_note() RETURNS trigger AS $$
BEGIN
INSERT INTO edit_note_recipient (recipient, edit_note) (
SELECT edit.editor, NEW.id
FROM edit
WHERE edit.id = NEW.edit
);
RETURN NULL;
END;
$$ LANGUAGE 'plpgsql';

-- vi: set ts=4 sw=4 et :
Loading

0 comments on commit 30824f0

Please sign in to comment.