diff options
Diffstat (limited to 'rust/migrations/2018-05-12-001226_init')
-rw-r--r-- | rust/migrations/2018-05-12-001226_init/up.sql | 87 |
1 files changed, 43 insertions, 44 deletions
diff --git a/rust/migrations/2018-05-12-001226_init/up.sql b/rust/migrations/2018-05-12-001226_init/up.sql index b0733576..6b0e9c6e 100644 --- a/rust/migrations/2018-05-12-001226_init/up.sql +++ b/rust/migrations/2018-05-12-001226_init/up.sql @@ -1,26 +1,28 @@ -- written for Postgres 9.6 with OSSP extension for UUIDs -- ... but actually runs on Postgres 10 in qa/production -CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; +-- CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- uuid_generate_v1mc: timestamp ordered, random MAC address --- uuid_generate_v4: totally random +-- gen_random_uuid: totally random -- NB: could use LIKE clause, or "composite types" CREATE TABLE editor ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), username TEXT NOT NULL UNIQUE, is_admin BOOLEAN NOT NULL DEFAULT false, registered TIMESTAMP WITHOUT TIME ZONE DEFAULT now() NOT NULL, active_editgroup_id UUID -- REFERENCES( editgroup(id) via ALTER below ); +CREATE INDEX active_editgroup_idx ON editor(active_editgroup_id); + CREATE TABLE editgroup ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), editor_id UUID REFERENCES editor(id) NOT NULL, created TIMESTAMP WITHOUT TIME ZONE DEFAULT now() NOT NULL, - extra_json JSON, + extra_json JSONB, description TEXT ); @@ -44,8 +46,8 @@ CREATE TABLE abstracts ( -------------------- Creators ----------------------------------------------- CREATE TABLE creator_rev ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - extra_json JSON, + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + extra_json JSONB, display_name TEXT NOT NULL, given_name TEXT, @@ -59,11 +61,11 @@ CREATE TABLE creator_rev ( -- Could denormalize a "is_live" flag into revision tables, to make indices -- more efficient -CREATE INDEX creator_rev_orcid_idx ON creator_rev(orcid) WHERE orcid IS NOT NULL; -CREATE INDEX creator_rev_wikidata_idx ON creator_rev(wikidata_qid) WHERE wikidata_qid IS NOT NULL; +CREATE INDEX creator_rev_orcid_idx ON creator_rev(orcid); -- WHERE orcid IS NOT NULL; +CREATE INDEX creator_rev_wikidata_idx ON creator_rev(wikidata_qid); -- WHERE wikidata_qid IS NOT NULL; CREATE TABLE creator_ident ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), is_live BOOL NOT NULL DEFAULT false, rev_id UUID REFERENCES creator_rev(id), redirect_id UUID REFERENCES creator_ident(id) @@ -79,15 +81,15 @@ CREATE TABLE creator_edit ( rev_id UUID REFERENCES creator_rev(id), redirect_id UUID REFERENCES creator_ident(id), prev_rev UUID REFERENCES creator_rev(id), - extra_json JSON + extra_json JSONB ); CREATE INDEX creator_edit_idx ON creator_edit(editgroup_id); -------------------- Containers -------------------------------------------- CREATE TABLE container_rev ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - extra_json JSON, + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + extra_json JSONB, name TEXT NOT NULL, publisher TEXT, @@ -97,11 +99,11 @@ CREATE TABLE container_rev ( coden TEXT ); -CREATE INDEX container_rev_issnl_idx ON container_rev(issnl) WHERE issnl IS NOT NULL; -CREATE INDEX container_rev_wikidata_idx ON container_rev(wikidata_qid) WHERE wikidata_qid IS NOT NULL; +CREATE INDEX container_rev_issnl_idx ON container_rev(issnl); -- WHERE issnl IS NOT NULL; +CREATE INDEX container_rev_wikidata_idx ON container_rev(wikidata_qid); -- WHERE wikidata_qid IS NOT NULL; CREATE TABLE container_ident ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), is_live BOOL NOT NULL DEFAULT false, rev_id UUID REFERENCES container_rev(id), redirect_id UUID REFERENCES container_ident(id) @@ -117,15 +119,15 @@ CREATE TABLE container_edit ( rev_id UUID REFERENCES container_rev(id), redirect_id UUID REFERENCES container_ident(id), prev_rev UUID REFERENCES container_rev(id), - extra_json JSON + extra_json JSONB ); CREATE INDEX container_edit_idx ON container_edit(editgroup_id); -------------------- Files ------------------------------------------------- CREATE TABLE file_rev ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - extra_json JSON, + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + extra_json JSONB, size BIGINT, sha1 CHAR(40), @@ -134,9 +136,9 @@ CREATE TABLE file_rev ( mimetype TEXT ); -CREATE INDEX file_rev_sha1_idx ON file_rev(sha1) WHERE sha1 IS NOT NULL; -CREATE INDEX file_rev_md5_idx ON file_rev(md5) WHERE md5 IS NOT NULL; -CREATE INDEX file_rev_sha256_idx ON file_rev(sha256) WHERE sha256 IS NOT NULL; +CREATE INDEX file_rev_sha1_idx ON file_rev(sha1); -- WHERE sha1 IS NOT NULL; +CREATE INDEX file_rev_md5_idx ON file_rev(md5); -- WHERE md5 IS NOT NULL; +CREATE INDEX file_rev_sha256_idx ON file_rev(sha256); -- WHERE sha256 IS NOT NULL; CREATE TABLE file_rev_url ( id BIGSERIAL PRIMARY KEY, @@ -148,7 +150,7 @@ CREATE TABLE file_rev_url ( CREATE INDEX file_rev_url_rev_idx ON file_rev_url(file_rev); CREATE TABLE file_ident ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), is_live BOOL NOT NULL DEFAULT false, rev_id UUID REFERENCES file_rev(id), redirect_id UUID REFERENCES file_ident(id) @@ -164,15 +166,15 @@ CREATE TABLE file_edit ( rev_id UUID REFERENCES file_rev(id), redirect_id UUID REFERENCES file_ident(id), prev_rev UUID REFERENCES file_rev(id), - extra_json JSON + extra_json JSONB ); CREATE INDEX file_edit_idx ON file_edit(editgroup_id); -------------------- Release ----------------------------------------------- CREATE TABLE release_rev ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - extra_json JSON, + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + extra_json JSONB, work_ident_id UUID NOT NULL, -- FOREIGN KEY; see ALRTER below container_ident_id UUID REFERENCES container_ident(id), @@ -195,13 +197,13 @@ CREATE TABLE release_rev ( -- TODO: identifier table? ); -CREATE INDEX release_rev_doi_idx ON release_rev(doi) WHERE doi IS NOT NULL; -CREATE INDEX release_rev_pmid_idx ON release_rev(pmid) WHERE pmid IS NOT NULL; -CREATE INDEX release_rev_pmcid_idx ON release_rev(pmcid) WHERE pmcid IS NOT NULL; -CREATE INDEX release_rev_wikidata_idx ON release_rev(wikidata_qid) WHERE wikidata_qid IS NOT NULL; -CREATE INDEX release_rev_isbn13_idx ON release_rev(isbn13) WHERE isbn13 IS NOT NULL; -CREATE INDEX release_rev_core_idx ON release_rev(core_id) WHERE core_id IS NOT NULL; -CREATE INDEX release_rev_work_idx ON release_rev(work_ident_id) WHERE work_ident_id IS NOT NULL; +CREATE INDEX release_rev_doi_idx ON release_rev(doi); -- WHERE doi IS NOT NULL; +CREATE INDEX release_rev_pmid_idx ON release_rev(pmid); -- WHERE pmid IS NOT NULL; +CREATE INDEX release_rev_pmcid_idx ON release_rev(pmcid); -- WHERE pmcid IS NOT NULL; +CREATE INDEX release_rev_wikidata_idx ON release_rev(wikidata_qid); -- WHERE wikidata_qid IS NOT NULL; +CREATE INDEX release_rev_isbn13_idx ON release_rev(isbn13); -- WHERE isbn13 IS NOT NULL; +CREATE INDEX release_rev_core_idx ON release_rev(core_id); -- WHERE core_id IS NOT NULL; +CREATE INDEX release_rev_work_idx ON release_rev(work_ident_id); -- WHERE work_ident_id IS NOT NULL; CREATE TABLE release_rev_abstract ( id BIGSERIAL PRIMARY KEY, @@ -211,11 +213,8 @@ CREATE TABLE release_rev_abstract ( lang TEXT ); -CREATE INDEX release_rev_abstract_rev_idx ON release_rev_abstract(release_rev); -CREATE INDEX release_rev_abstract_sha1_idx ON release_rev_abstract(abstract_sha1); - CREATE TABLE release_ident ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), is_live BOOL NOT NULL DEFAULT false, rev_id UUID REFERENCES release_rev(id), redirect_id UUID REFERENCES release_ident(id) @@ -231,19 +230,19 @@ CREATE TABLE release_edit ( rev_id UUID REFERENCES release_rev(id), redirect_id UUID REFERENCES release_ident(id), prev_rev UUID REFERENCES release_rev(id), - extra_json JSON + extra_json JSONB ); CREATE INDEX release_edit_idx ON release_edit(editgroup_id); -------------------- Works -------------------------------------------------- CREATE TABLE work_rev ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - extra_json JSON + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + extra_json JSONB ); CREATE TABLE work_ident ( - id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), is_live BOOL NOT NULL DEFAULT false, rev_id UUID REFERENCES work_rev(id), redirect_id UUID REFERENCES work_ident(id) @@ -259,7 +258,7 @@ CREATE TABLE work_edit ( rev_id UUID REFERENCES work_rev(id), redirect_id UUID REFERENCES work_ident(id), prev_rev UUID REFERENCES work_rev(id), - extra_json JSON + extra_json JSONB ); CREATE INDEX work_edit_idx ON work_edit(editgroup_id); @@ -277,7 +276,7 @@ CREATE TABLE release_contrib ( raw_name TEXT, role TEXT, -- TODO: enum? index_val BIGINT, - extra_json JSON + extra_json JSONB ); CREATE INDEX release_contrib_rev_idx ON release_contrib(release_rev); @@ -289,7 +288,7 @@ CREATE TABLE release_ref ( target_release_ident_id UUID REFERENCES release_ident(id), -- or work? index_val BIGINT, key TEXT, - extra_json JSON, -- title, year, container_title, locator (aka, page), oci_id + extra_json JSONB, -- title, year, container_title, locator (aka, page), oci_id container_title TEXT, year BIGINT, title TEXT, |