aboutsummaryrefslogtreecommitdiffstats
path: root/rust/migrations/2018-05-12-001226_init/up.sql
blob: 6d8471eb726ca71ba5abfc4b47faf877d9a99117 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
-- written for Postgres 9.6 with OSSP extension for UUIDs

CREATE EXTENSION IF NOT EXISTS "uuid-ossp";


-- uuid_generate_v1mc: timestamp ordered, random MAC address
-- uuid_generate_v4:   totally random

-- NB: could use LIKE clause, or "composite types"

CREATE TABLE editor (
    id                  BIGSERIAL PRIMARY KEY,
    username            TEXT NOT NULL,
    is_admin            BOOLEAN NOT NULL DEFAULT false,
    active_editgroup_id BIGINT -- REFERENCES( editgroup(id) via ALTER below
);

CREATE TABLE editgroup (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,
    editor_id           BIGSERIAL REFERENCES editor(id) NOT NULL,
    description         TEXT
);

ALTER TABLE editor
    ADD CONSTRAINT editor_editgroupid_fkey FOREIGN KEY (active_editgroup_id)
        REFERENCES editgroup(id);

CREATE TABLE changelog (
    id                  BIGSERIAL PRIMARY KEY,
    editgroup_id        BIGINT REFERENCES editgroup(id) NOT NULL,
    timestamp           TIMESTAMP WITHOUT TIME ZONE DEFAULT now() NOT NULL
);

-------------------- Creators -----------------------------------------------
CREATE TABLE creator_rev (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,

    name                TEXT NOT NULL,
    orcid               TEXT
);

-- 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 TABLE creator_ident (
    id                  UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
    is_live             BOOL NOT NULL DEFAULT false,
    rev_id              BIGINT REFERENCES creator_rev(id),
    redirect_id         UUID REFERENCES creator_ident(id)
);

CREATE TABLE creator_edit (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,
    ident_id            UUID REFERENCES creator_ident(id) NOT NULL,
    rev_id              BIGINT REFERENCES creator_rev(id),
    redirect_id         UUID REFERENCES creator_ident(id),
    editgroup_id        BIGINT REFERENCES editgroup(id) NOT NULL
);

-------------------- Containers --------------------------------------------
CREATE TABLE container_rev (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,

    name                TEXT NOT NULL,
    publisher           TEXT,
    issn                TEXT -- TODO: varchar
);

CREATE INDEX container_rev_issn_idx ON container_rev(issn) WHERE issn IS NOT NULL;

CREATE TABLE container_ident (
    id                  UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
    is_live             BOOL NOT NULL DEFAULT false,
    rev_id              BIGINT REFERENCES container_rev(id),
    redirect_id         UUID REFERENCES container_ident(id)
);

CREATE TABLE container_edit (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,
    ident_id            UUID REFERENCES container_ident(id) NOT NULL,
    rev_id              BIGINT REFERENCES container_rev(id),
    redirect_id         UUID REFERENCES container_ident(id),
    editgroup_id        BIGINT REFERENCES editgroup(id) NOT NULL
);

-------------------- Files -------------------------------------------------
CREATE TABLE file_rev (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,

    size                INTEGER, -- TODO: uint64
    sha1                TEXT, -- TODO: varchar or bytes
    url                 TEXT  -- TODO: URL table
);

CREATE TABLE file_ident (
    id                  UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
    is_live             BOOL NOT NULL DEFAULT false,
    rev_id              BIGINT REFERENCES file_rev(id),
    redirect_id         UUID REFERENCES file_ident(id)
);

CREATE TABLE file_edit (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,
    ident_id            UUID REFERENCES file_ident(id) NOT NULL,
    rev_id              BIGINT REFERENCES file_rev(id),
    redirect_id         UUID REFERENCES file_ident(id),
    editgroup_id        BIGINT REFERENCES editgroup(id) NOT NULL
);

-------------------- Release -----------------------------------------------
CREATE TABLE release_rev (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,

    work_ident_id       UUID NOT NULL, -- FOREIGN KEY; see ALRTER below
    container_ident_id  UUID REFERENCES container_ident(id),
    title               TEXT NOT NULL,
    release_type        TEXT, -- TODO: enum
    date                TEXT, -- XXX: datetime
    doi                 TEXT, -- TODO: identifier table?
    volume              TEXT,
    pages               TEXT,
    issue               TEXT
);

CREATE INDEX release_rev_doi_idx ON release_rev(doi) WHERE doi IS NOT NULL;

CREATE TABLE release_ident (
    id                  UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
    is_live             BOOL NOT NULL DEFAULT false,
    rev_id              BIGINT REFERENCES release_rev(id),
    redirect_id         UUID REFERENCES release_ident(id)
);

CREATE TABLE release_edit (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,
    ident_id            UUID REFERENCES release_ident(id) NOT NULL,
    rev_id              BIGINT REFERENCES release_rev(id),
    redirect_id         UUID REFERENCES release_ident(id),
    editgroup_id        BIGINT REFERENCES editgroup(id) NOT NULL
);

-------------------- Works --------------------------------------------------
CREATE TABLE work_rev (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,

    -- not even a work, for now
    work_type           TEXT, -- TODO: enum?
    primary_release_id  UUID REFERENCES release_ident(id)
);

CREATE TABLE work_ident (
    id                  UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
    is_live             BOOL NOT NULL DEFAULT false,
    rev_id              BIGINT REFERENCES work_rev(id),
    redirect_id         UUID REFERENCES work_ident(id)
);

CREATE TABLE work_edit (
    id                  BIGSERIAL PRIMARY KEY,
    -- extra_json          JSON,
    ident_id            UUID REFERENCES work_ident(id) NOT NULL,
    rev_id              BIGINT REFERENCES work_rev(id),
    redirect_id         UUID REFERENCES work_ident(id),
    editgroup_id        BIGINT REFERENCES editgroup(id) NOT NULL
);


ALTER TABLE release_rev
    ADD CONSTRAINT release_containeridentid_fkey FOREIGN KEY (work_ident_id)
            REFERENCES work_ident(id);

-------------------- Inter-Entity Relations

CREATE TABLE release_contrib (
    id                  BIGSERIAL PRIMARY KEY,
    release_rev         BIGSERIAL REFERENCES release_rev(id) NOT NULL,
    creator_ident_id    UUID REFERENCES creator_ident(id),
    stub                TEXT,
    contrib_type        TEXT
);

CREATE TABLE release_ref (
    id                      BIGSERIAL PRIMARY KEY,
    release_rev             BIGSERIAL REFERENCES release_rev(id) NOT NULL,
    target_release_ident_id UUID REFERENCES release_ident(id), -- or work?
    index                   INTEGER,
    stub                    TEXT
);

CREATE TABLE file_release (
    file_rev                BIGSERIAL REFERENCES file_rev(id) NOT NULL,
    target_release_ident_id UUID REFERENCES creator_ident(id) NOT NULL,
    PRIMARY KEY (file_rev, target_release_ident_id)
);