aboutsummaryrefslogtreecommitdiff
path: root/sqitch/deploy/initial_import.sql
blob: 238922d0c5eb4553725b82667afe824d3aa2ee5c (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
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
-- Deploy guix-data-service:initial_import to pg

BEGIN;


CREATE TABLE guix_data_service.build_servers (
    id integer NOT NULL,
    url character varying NOT NULL,
    lookup_all_derivations boolean NOT NULL
);

ALTER TABLE guix_data_service.build_servers ALTER COLUMN id ADD GENERATED ALWAYS AS IDENTITY (
    SEQUENCE NAME guix_data_service.build_servers_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


CREATE TABLE guix_data_service.build_status (
    id integer NOT NULL,
    status_fetched_at timestamp without time zone DEFAULT clock_timestamp() NOT NULL,
    internal_build_id integer NOT NULL,
    starttime timestamp without time zone,
    stoptime timestamp without time zone,
    status guix_data_service.buildstatus NOT NULL
);

ALTER TABLE guix_data_service.build_status ALTER COLUMN id ADD GENERATED ALWAYS AS IDENTITY (
    SEQUENCE NAME guix_data_service.build_status_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


CREATE TABLE guix_data_service.builds (
    internal_id integer NOT NULL,
    id integer NOT NULL,
    build_server_id integer NOT NULL,
    derivation_id integer NOT NULL,
    "timestamp" timestamp without time zone NOT NULL
);

ALTER TABLE guix_data_service.builds ALTER COLUMN internal_id ADD GENERATED ALWAYS AS IDENTITY (
    SEQUENCE NAME guix_data_service.builds_internal_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


CREATE TABLE guix_data_service.derivation_inputs (
    derivation_id integer NOT NULL,
    derivation_output_id integer NOT NULL
);


CREATE TABLE guix_data_service.derivation_output_details (
    id integer NOT NULL,
    path character varying NOT NULL,
    hash_algorithm character varying,
    hash character varying,
    recursive boolean NOT NULL
);

ALTER TABLE guix_data_service.derivation_output_details ALTER COLUMN id ADD GENERATED ALWAYS AS IDENTITY (
    SEQUENCE NAME guix_data_service.derivation_output_details_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


CREATE TABLE guix_data_service.derivation_outputs (
    derivation_id integer NOT NULL,
    name character varying NOT NULL,
    derivation_output_details_id integer NOT NULL,
    id integer NOT NULL
);

ALTER TABLE guix_data_service.derivation_outputs ALTER COLUMN id ADD GENERATED ALWAYS AS IDENTITY (
    SEQUENCE NAME guix_data_service.derivation_outputs_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


CREATE TABLE guix_data_service.derivation_source_files (
    id integer NOT NULL,
    store_path character varying NOT NULL
);

ALTER TABLE guix_data_service.derivation_source_files ALTER COLUMN id ADD GENERATED ALWAYS AS IDENTITY (
    SEQUENCE NAME guix_data_service.derivation_source_files_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);

CREATE TABLE guix_data_service.derivation_sources (
    derivation_id integer NOT NULL,
    derivation_source_file_id integer NOT NULL
);


CREATE TABLE guix_data_service.derivations (
    id integer NOT NULL,
    file_name character varying NOT NULL,
    builder character varying NOT NULL,
    args character varying[] DEFAULT ARRAY[''::text] NOT NULL,
    env_vars character varying[] DEFAULT ARRAY[]::character varying[] NOT NULL,
    system character varying DEFAULT ''::character varying NOT NULL
);

ALTER TABLE guix_data_service.derivations ALTER COLUMN id ADD GENERATED BY DEFAULT AS IDENTITY (
    SEQUENCE NAME guix_data_service.derivations_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


CREATE TABLE guix_data_service.guix_revision_package_derivations (
    revision_id integer NOT NULL,
    package_derivation_id integer NOT NULL
);


CREATE TABLE guix_data_service.guix_revisions (
    id integer NOT NULL,
    url character varying NOT NULL,
    commit character varying NOT NULL,
    store_path character varying NOT NULL
);

ALTER TABLE guix_data_service.guix_revisions ALTER COLUMN id ADD GENERATED BY DEFAULT AS IDENTITY (
    SEQUENCE NAME guix_data_service.guix_revisions_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


CREATE TABLE guix_data_service.load_new_guix_revision_jobs (
    id integer NOT NULL,
    url character varying NOT NULL,
    commit character varying NOT NULL,
    source character varying NOT NULL
);

ALTER TABLE guix_data_service.load_new_guix_revision_jobs ALTER COLUMN id ADD GENERATED ALWAYS AS IDENTITY (
    SEQUENCE NAME guix_data_service.load_new_guix_revision_jobs_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


CREATE TABLE guix_data_service.package_derivations (
    id integer NOT NULL,
    package_id integer NOT NULL,
    derivation_id integer NOT NULL,
    system character varying NOT NULL,
    target character varying NOT NULL
);

ALTER TABLE guix_data_service.package_derivations ALTER COLUMN id ADD GENERATED ALWAYS AS IDENTITY (
    SEQUENCE NAME guix_data_service.package_derivations_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


CREATE TABLE guix_data_service.package_metadata (
    id integer NOT NULL,
    sha1_hash character(40) NOT NULL,
    synopsis character varying,
    description character varying,
    home_page character varying
);

ALTER TABLE guix_data_service.package_metadata ALTER COLUMN id ADD GENERATED BY DEFAULT AS IDENTITY (
    SEQUENCE NAME guix_data_service.package_metadata_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


CREATE TABLE guix_data_service.packages (
    id integer NOT NULL,
    name character varying NOT NULL,
    version character varying NOT NULL,
    package_metadata_id integer NOT NULL
);

ALTER TABLE guix_data_service.packages ALTER COLUMN id ADD GENERATED BY DEFAULT AS IDENTITY (
    SEQUENCE NAME guix_data_service.packages_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MINVALUE
    NO MAXVALUE
    CACHE 1
);


ALTER TABLE ONLY guix_data_service.build_servers
    ADD CONSTRAINT build_servers_id_key UNIQUE (id);

ALTER TABLE ONLY guix_data_service.build_servers
    ADD CONSTRAINT build_servers_pkey PRIMARY KEY (url);

ALTER TABLE ONLY guix_data_service.build_status
    ADD CONSTRAINT build_status_id_key UNIQUE (id);

ALTER TABLE ONLY guix_data_service.builds
    ADD CONSTRAINT builds_internal_id_key UNIQUE (internal_id);

ALTER TABLE ONLY guix_data_service.builds
    ADD CONSTRAINT builds_pkey PRIMARY KEY (id, build_server_id);

ALTER TABLE ONLY guix_data_service.derivation_inputs
    ADD CONSTRAINT derivation_inputs_pkey PRIMARY KEY (derivation_id, derivation_output_id);

ALTER TABLE ONLY guix_data_service.derivation_output_details
    ADD CONSTRAINT derivation_output_details_id_unique UNIQUE (id);

ALTER TABLE ONLY guix_data_service.derivation_output_details
    ADD CONSTRAINT derivation_output_details_pkey PRIMARY KEY (path);

ALTER TABLE ONLY guix_data_service.derivation_outputs
    ADD CONSTRAINT derivation_outputs_pkey PRIMARY KEY (derivation_id, name);

ALTER TABLE ONLY guix_data_service.derivation_outputs
    ADD CONSTRAINT derivation_outputs_unique_id UNIQUE (id);

ALTER TABLE ONLY guix_data_service.derivation_source_files
    ADD CONSTRAINT derivation_source_files_id_unique UNIQUE (id);

ALTER TABLE ONLY guix_data_service.derivation_source_files
    ADD CONSTRAINT derivation_source_files_pkey PRIMARY KEY (store_path);

ALTER TABLE ONLY guix_data_service.derivation_sources
    ADD CONSTRAINT derivation_sources_pkey PRIMARY KEY (derivation_id, derivation_source_file_id);

ALTER TABLE ONLY guix_data_service.derivations
    ADD CONSTRAINT derivations_pkey PRIMARY KEY (file_name);

ALTER TABLE ONLY guix_data_service.derivations
    ADD CONSTRAINT file_name_unique UNIQUE (file_name);

ALTER TABLE ONLY guix_data_service.guix_revision_package_derivations
    ADD CONSTRAINT guix_revision_package_derivations_pkey PRIMARY KEY (revision_id, package_derivation_id);

ALTER TABLE ONLY guix_data_service.guix_revisions
    ADD CONSTRAINT guix_revisions_pkey PRIMARY KEY (id);

ALTER TABLE ONLY guix_data_service.derivations
    ADD CONSTRAINT id_unique UNIQUE (id);

ALTER TABLE ONLY guix_data_service.package_derivations
    ADD CONSTRAINT package_derivations_id_key UNIQUE (id);

ALTER TABLE ONLY guix_data_service.package_derivations
    ADD CONSTRAINT package_derivations_pkey PRIMARY KEY (package_id, derivation_id, system, target);

ALTER TABLE ONLY guix_data_service.package_metadata
    ADD CONSTRAINT package_metadata_pkey PRIMARY KEY (id);

ALTER TABLE ONLY guix_data_service.packages
    ADD CONSTRAINT packages_id_key UNIQUE (id);

ALTER TABLE ONLY guix_data_service.packages
    ADD CONSTRAINT packages_pkey PRIMARY KEY (name, version, package_metadata_id);

ALTER TABLE ONLY guix_data_service.package_metadata
    ADD CONSTRAINT synopsis_description_home_page UNIQUE (synopsis, description, home_page);

ALTER TABLE ONLY guix_data_service.package_metadata
    ADD CONSTRAINT unique_sha1_hash UNIQUE (sha1_hash);


CREATE INDEX build_status_internal_build_id_and_status_fetched_at_desc ON guix_data_service.build_status USING btree (internal_build_id, status_fetched_at DESC);

CREATE INDEX builds_derivation_id ON guix_data_service.builds USING hash (derivation_id);

CREATE INDEX derivation_inputs_derivation_output_id_idx ON guix_data_service.derivation_inputs USING btree (derivation_output_id);

CREATE INDEX guix_revisions_commit_idx ON guix_data_service.guix_revisions USING hash (commit);

CREATE INDEX package_derivations_derivation_id ON guix_data_service.package_derivations USING hash (derivation_id);


ALTER TABLE ONLY guix_data_service.build_status
    ADD CONSTRAINT build_status_internal_build_id_fkey FOREIGN KEY (internal_build_id) REFERENCES guix_data_service.builds(internal_id);

ALTER TABLE ONLY guix_data_service.builds
    ADD CONSTRAINT builds_build_server_id_fkey FOREIGN KEY (build_server_id) REFERENCES guix_data_service.build_servers(id);

ALTER TABLE ONLY guix_data_service.builds
    ADD CONSTRAINT builds_derivation_id_fkey FOREIGN KEY (derivation_id) REFERENCES guix_data_service.derivations(id);

ALTER TABLE ONLY guix_data_service.derivation_inputs
    ADD CONSTRAINT derivation_id_fk FOREIGN KEY (derivation_id) REFERENCES guix_data_service.derivations(id);

ALTER TABLE ONLY guix_data_service.derivation_inputs
    ADD CONSTRAINT derivation_output_id_fk FOREIGN KEY (derivation_output_id) REFERENCES guix_data_service.derivation_outputs(id);

ALTER TABLE ONLY guix_data_service.derivation_outputs
    ADD CONSTRAINT derivation_outputs_derivation_id_fk FOREIGN KEY (derivation_id) REFERENCES guix_data_service.derivations(id);

ALTER TABLE ONLY guix_data_service.derivation_outputs
    ADD CONSTRAINT derivation_outputs_derivation_output_details_id_fk FOREIGN KEY (derivation_output_details_id) REFERENCES guix_data_service.derivation_output_details(id);

ALTER TABLE ONLY guix_data_service.derivation_sources
    ADD CONSTRAINT derivation_sources_derivation_source_file_id_fk FOREIGN KEY (derivation_source_file_id) REFERENCES guix_data_service.derivation_source_files(id);

ALTER TABLE ONLY guix_data_service.derivation_sources
    ADD CONSTRAINT dervaition_sources_derivation_id_fk FOREIGN KEY (derivation_id) REFERENCES guix_data_service.derivations(id);

ALTER TABLE ONLY guix_data_service.guix_revision_package_derivations
    ADD CONSTRAINT guix_revision_package_derivations_package_derivation_id_fkey FOREIGN KEY (package_derivation_id) REFERENCES guix_data_service.package_derivations(id);

ALTER TABLE ONLY guix_data_service.guix_revision_package_derivations
    ADD CONSTRAINT guix_revision_package_derivations_revision_id_fkey FOREIGN KEY (revision_id) REFERENCES guix_data_service.guix_revisions(id);

ALTER TABLE ONLY guix_data_service.packages
    ADD CONSTRAINT package_metadata_id FOREIGN KEY (package_metadata_id) REFERENCES guix_data_service.package_metadata(id);


GRANT USAGE ON SCHEMA guix_data_service TO guix_data_service;

COMMIT;