1 -- -*- mode: sql; sql-product: postgres; -*-
2 DROP TABLE bug_status_cache CASCADE;
3 DROP VIEW bug_package CASCADE;
4 DROP VIEW binary_versions CASCADE;
5 DROP VIEW bug_status CASCADE;
6 DROP TABLE bug_tag CASCADE;
7 DROP TABLE tag CASCADE;
8 DROP TABLE bug_user_tag CASCADE;
9 DROP TABLE user_tag CASCADE;
10 DROP TABLE severity CASCADE;
11 DROP TABLE bug CASCADE;
12 DROP TABLE src_pkg CASCADE;
13 DROP TABLE bug_ver CASCADE;
14 DROP TABLE src_ver CASCADE;
15 DROP TABLE arch CASCADE;
16 DROP TABLE bin_ver CASCADE;
17 DROP TABLE bin_pkg CASCADE;
18 DROP TABLE bug_blocks CASCADE;
19 DROP TABLE bug_merged CASCADE;
20 DROP TABLE bug_srcpackage CASCADE;
21 DROP TABLE bug_binpackage CASCADE;
22 DROP TABLE bug_affects_binpackage CASCADE;
23 DROP TABLE bug_affects_srcpackage CASCADE;
24 DROP TABLE suite CASCADE;
25 DROP TABLE bin_associations CASCADE;
26 DROP TABLE src_associations CASCADE;
27 DROP TABLE maintainer CASCADE;
28 DROP TABLE bug_message CASCADE;
29 DROP TABLE message_correspondent CASCADE;
30 DROP TABLE correspondent_full_name CASCADE;
31 DROP TABLE correspondent CASCADE;
32 DROP TABLE message_refs CASCADE;
33 DROP TABLE message CASCADE;
34 DROP TYPE message_correspondent_type CASCADE;
35 DROP TABLE table_comments CASCADE;
36 DROP TABLE column_comments CASCADE;
37 DROP TYPE bug_status_type CASCADE;
39 -- the following two tables are used to provide documentation about
40 -- the tables and columns for DBIx::Class::Schema::Loader
41 CREATE TABLE table_comments (
42 table_name TEXT NOT NULL,
43 comment_text TEXT NOT NULL
45 CREATE UNIQUE INDEX table_comments_table_name_idx ON table_comments(table_name);
46 CREATE TABLE column_comments (
47 table_name TEXT NOT NULL,
48 column_name TEXT NOT NULL,
49 comment_text TEXT NOT NULL
51 CREATE UNIQUE INDEX column_comments_table_name_column_name_idx ON column_comments(table_name,column_name);
54 CREATE TABLE correspondent (
55 id SERIAL PRIMARY KEY,
58 CREATE UNIQUE INDEX correspondent_addr_idx ON correspondent(addr);
59 INSERT INTO table_comments VALUES ('correspondent','Individual who has corresponded with the BTS');
60 INSERT INTO column_comments VALUES ('correspondent','id','Correspondent ID');
61 INSERT INTO column_comments VALUES ('correspondent','addr','Correspondent address');
63 CREATE TABLE maintainer (
64 id SERIAL PRIMARY KEY,
66 correspondent INT NOT NULL REFERENCES correspondent(id),
67 created TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
68 modified TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL
70 CREATE UNIQUE INDEX maintainer_name_idx ON maintainer(name);
71 CREATE INDEX maintainer_idx_correspondent ON maintainer(correspondent);
72 INSERT INTO table_comments VALUES ('maintainer','Package maintainer names');
73 INSERT INTO column_comments VALUES ('maintainer','id','Package maintainer id');
74 INSERT INTO column_comments VALUES ('maintainer','name','Name of package maintainer');
75 INSERT INTO column_comments VALUES ('maintainer','correspondent','Correspondent ID');
76 INSERT INTO column_comments VALUES ('maintainer','created','Time maintainer record created');
77 INSERT INTO column_comments VALUES ('maintainer','modified','Time maintainer record modified');
80 CREATE TABLE severity (
81 id SERIAL PRIMARY KEY,
82 severity TEXT NOT NULL,
83 ordering INT NOT NULL DEFAULT 5,
84 strong BOOLEAN DEFAULT FALSE,
85 obsolete BOOLEAN DEFAULT FALSE
87 CREATE UNIQUE INDEX severity_severity_idx ON severity(severity);
88 CREATE INDEX severity_ordering_idx ON severity(ordering);
89 INSERT INTO table_comments VALUES ('severity','Bug severity');
90 INSERT INTO column_comments VALUES ('severity','id','Severity id');
91 INSERT INTO column_comments VALUES ('severity','severity','Severity name');
92 INSERT INTO column_comments VALUES ('severity','ordering','Severity ordering (more severe severities have higher numbers)');
93 INSERT INTO column_comments VALUES ('severity','strong','True if severity is a strong severity');
94 INSERT INTO column_comments VALUES ('severity','obsolete','Whether a severity level is obsolete (should not be set on new bugs)');
98 id INTEGER NOT NULL PRIMARY KEY,
99 creation TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
100 log_modified TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
101 last_modified TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
102 archived BOOLEAN NOT NULL DEFAULT FALSE,
103 unarchived TIMESTAMP WITH TIME ZONE,
104 forwarded TEXT NOT NULL DEFAULT '',
105 summary TEXT NOT NULL DEFAULT '',
106 outlook TEXT NOT NULL DEFAULT '',
107 subject TEXT NOT NULL,
108 severity INT NOT NULL REFERENCES severity(id),
109 done INT REFERENCES correspondent(id),
110 done_full TEXT NOT NULL DEFAULT '',
111 owner INT REFERENCES correspondent(id),
112 owner_full TEXT NOT NULL DEFAULT '',
113 -- submitter would ideally be NOT NULL, but there are some ancient bugs which do not have submitters
114 submitter INT REFERENCES correspondent(id),
115 submitter_full TEXT NOT NULL DEFAULT '',
116 unknown_packages TEXT NOT NULL DEFAULT '',
117 unknown_affects TEXT NOT NULL DEFAULT ''
119 CREATE INDEX bug_idx_owner ON bug(owner);
120 CREATE INDEX bug_idx_submitter ON bug(submitter);
121 CREATE INDEX bug_idx_done ON bug(done);
122 CREATE INDEX bug_idx_forwarded ON bug(forwarded);
123 CREATE INDEX bug_idx_last_modified ON bug(last_modified);
124 CREATE INDEX bug_idx_severity ON bug(severity);
125 CREATE INDEX bug_idx_creation ON bug(creation);
126 CREATE INDEX bug_idx_log_modified ON bug(log_modified);
128 INSERT INTO table_comments VALUES ('bug','Bugs');
129 INSERT INTO column_comments VALUES ('bug','id','Bug number');
130 INSERT INTO column_comments VALUES ('bug','creation','Time bug created');
131 INSERT INTO column_comments VALUES ('bug','log_modified','Time bug log was last modified');
132 INSERT INTO column_comments VALUES ('bug','last_modified','Time bug status was last modified');
133 INSERT INTO column_comments VALUES ('bug','archived','True if bug has been archived');
134 INSERT INTO column_comments VALUES ('bug','unarchived','Time bug was last unarchived; null if bug has never been unarchived');
135 INSERT INTO column_comments VALUES ('bug','forwarded','Where bug has been forwarded to; empty if it has not been forwarded');
136 INSERT INTO column_comments VALUES ('bug','summary','Summary of the bug; empty if it has no summary');
137 INSERT INTO column_comments VALUES ('bug','outlook','Outlook of the bug; empty if it has no outlook');
138 INSERT INTO column_comments VALUES ('bug','subject','Subject of the bug');
139 INSERT INTO column_comments VALUES ('bug','done','Individual who did the -done; empty if it has never been -done');
140 INSERT INTO column_comments VALUES ('bug','owner','Individual who owns this bug; empty if no one owns it');
141 INSERT INTO column_comments VALUES ('bug','submitter','Individual who submitted this bug; empty if there is no submitter');
142 INSERT INTO column_comments VALUES ('bug','unknown_packages','Package name if the package is not known');
143 INSERT INTO column_comments VALUES ('bug','unknown_affects','Package name if the affected package is not known');
147 CREATE TABLE bug_blocks (
148 id SERIAL PRIMARY KEY,
149 bug INT NOT NULL REFERENCES bug,
150 blocks INT NOT NULL REFERENCES bug,
151 CONSTRAINT bug_doesnt_block_itself CHECK (bug <> blocks)
153 CREATE UNIQUE INDEX bug_blocks_bug_id_blocks_idx ON bug_blocks(bug,blocks);
154 CREATE INDEX bug_blocks_bug_id_idx ON bug_blocks(bug);
155 CREATE INDEX bug_blocks_blocks_idx ON bug_blocks(blocks);
156 INSERT INTO table_comments VALUES ('bug_blocks','Bugs which block other bugs');
157 INSERT INTO column_comments VALUES ('bug_blocks','bug','Bug number');
158 INSERT INTO column_comments VALUES ('bug_blocks','blocks','Bug number which is blocked by bug');
161 CREATE TABLE bug_merged (
162 id SERIAL PRIMARY KEY,
163 bug INT NOT NULL REFERENCES bug,
164 merged INT NOT NULL REFERENCES bug,
165 CONSTRAINT bug_doesnt_merged_itself CHECK (bug <> merged)
167 CREATE UNIQUE INDEX bug_merged_bug_id_merged_idx ON bug_merged(bug,merged);
168 CREATE INDEX bug_merged_bug_id_idx ON bug_merged(bug);
169 CREATE INDEX bug_merged_merged_idx ON bug_merged(merged);
170 INSERT INTO table_comments VALUES ('bug_merged','Bugs which are merged with other bugs');
171 INSERT INTO column_comments VALUES ('bug_merged','bug','Bug number');
172 INSERT INTO column_comments VALUES ('bug_merged','merged','Bug number which is merged with bug');
174 CREATE TABLE src_pkg (
175 id SERIAL PRIMARY KEY,
177 pseduopkg BOOLEAN NOT NULL DEFAULT FALSE,
178 alias_of INT REFERENCES src_pkg ON UPDATE CASCADE ON DELETE CASCADE,
179 creation TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
180 disabled TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT 'infinity'::timestamp with time zone,
181 last_modified TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
182 obsolete BOOLEAN NOT NULL DEFAULT FALSE,
183 CONSTRAINT src_pkg_doesnt_alias_itself CHECK (id <> alias_of),
184 CONSTRAINT src_pkg_is_obsolete_if_disabled CHECK (
185 (obsolete IS FALSE AND disabled='infinity'::timestamp with time zone) OR
186 (obsolete IS TRUE AND disabled < 'infinity'::timestamp with time zone))
188 CREATE INDEX src_pkg_pkg ON src_pkg(pkg);
189 CREATE UNIQUE INDEX src_pkg_pkg_null ON src_pkg(pkg) WHERE disabled='infinity'::timestamp with time zone;
190 CREATE UNIQUE INDEX src_pkg_pkg_disabled ON src_pkg(pkg,disabled);
191 INSERT INTO table_comments VALUES ('src_pkg','Source packages');
192 INSERT INTO column_comments VALUES ('src_pkg','id','Source package id');
193 INSERT INTO column_comments VALUES ('src_pkg','pkg','Source package name');
194 INSERT INTO column_comments VALUES ('src_pkg','pseudopkg','True if this is a pseudo package');
195 INSERT INTO column_comments VALUES ('src_pkg','alias_of','Source package id which this source package is an alias of');
199 CREATE TABLE src_ver (
200 id SERIAL PRIMARY KEY,
201 src_pkg INT NOT NULL REFERENCES src_pkg
202 ON UPDATE CASCADE ON DELETE CASCADE,
203 ver debversion NOT NULL,
204 maintainer INT REFERENCES maintainer
205 ON UPDATE CASCADE ON DELETE SET NULL,
206 upload_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
207 based_on INT REFERENCES src_ver
208 ON UPDATE CASCADE ON DELETE CASCADE
210 CREATE UNIQUE INDEX src_ver_src_pkg_id_ver ON src_ver(src_pkg,ver);
211 INSERT INTO table_comments VALUES ('src_ver','Source Package versions');
212 INSERT INTO column_comments VALUES ('src_ver','id','Source package version id');
213 INSERT INTO column_comments VALUES ('src_ver','src_pkg','Source package id (matches src_pkg table)');
214 INSERT INTO column_comments VALUES ('src_ver','ver','Version of the source package');
215 INSERT INTO column_comments VALUES ('src_ver','maintainer','Maintainer id (matches maintainer table)');
216 INSERT INTO column_comments VALUES ('src_ver','upload_date','Date this version of the source package was uploaded');
217 INSERT INTO column_comments VALUES ('src_ver','based_on','Source package version this version is based on');
221 CREATE TABLE bug_ver (
222 id SERIAL PRIMARY KEY,
223 bug INT NOT NULL REFERENCES bug
224 ON UPDATE CASCADE ON DELETE RESTRICT,
226 src_pkg INT REFERENCES src_pkg
227 ON UPDATE CASCADE ON DELETE SET NULL,
228 src_ver INT REFERENCES src_ver
229 ON UPDATE CASCADE ON DELETE SET NULL,
230 found BOOLEAN NOT NULL DEFAULT TRUE,
231 creation TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
232 last_modified TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
234 CREATE INDEX bug_ver_src_pkg_id_idx ON bug_ver(src_pkg);
235 CREATE INDEX bug_ver_src_pkg_id_src_ver_id_idx ON bug_ver(src_pkg,src_ver);
236 CREATE INDEX bug_ver_src_ver_id_idx ON bug_ver(src_ver);
237 CREATE UNIQUE INDEX bug_ver_bug_ver_string_found_idx ON bug_ver(bug,ver_string,found);
238 INSERT INTO table_comments VALUES ('bug_ver','Bug versions');
239 INSERT INTO column_comments VALUES ('bug_ver','id','Bug version id');
240 INSERT INTO column_comments VALUES ('bug_ver','bug','Bug number');
241 INSERT INTO column_comments VALUES ('bug_ver','ver_string','Version string');
242 INSERT INTO column_comments VALUES ('bug_ver','src_pkg','Source package id (matches src_pkg table)');
243 INSERT INTO column_comments VALUES ('bug_ver','src_ver','Source package version id (matches src_ver table)');
244 INSERT INTO column_comments VALUES ('bug_ver','found','True if this is a found version; false if this is a fixed version');
245 INSERT INTO column_comments VALUES ('bug_ver','creation','Time that this entry was created');
246 INSERT INTO column_comments VALUES ('bug_ver','last_modified','Time that this entry was modified');
250 id SERIAL PRIMARY KEY,
253 CREATE UNIQUE INDEX arch_arch_key ON arch(arch);
254 INSERT INTO table_comments VALUES ('arch','Architectures');
255 INSERT INTO column_comments VALUES ('arch','id','Architecture id');
256 INSERT INTO column_comments VALUES ('arch','arch','Architecture name');
259 CREATE TABLE bin_pkg (
260 id SERIAL PRIMARY KEY,
263 CREATE UNIQUE INDEX bin_pkg_pkg_key ON bin_pkg(pkg);
264 INSERT INTO table_comments VALUES ('bin_pkg','Binary packages');
265 INSERT INTO column_comments VALUES ('bin_pkg','id','Binary package id');
266 INSERT INTO column_comments VALUES ('bin_pkg','pkg','Binary package name');
269 CREATE TABLE bin_ver(
270 id SERIAL PRIMARY KEY,
271 bin_pkg INT NOT NULL REFERENCES bin_pkg
272 ON UPDATE CASCADE ON DELETE CASCADE,
273 src_ver INT NOT NULL REFERENCES src_ver
274 ON UPDATE CASCADE ON DELETE CASCADE,
275 arch INT NOT NULL REFERENCES arch
276 ON UPDATE CASCADE ON DELETE CASCADE,
277 ver debversion NOT NULL
279 CREATE INDEX bin_ver_ver_idx ON bin_ver(ver);
280 CREATE UNIQUE INDEX bin_ver_bin_pkg_id_arch_idx ON bin_ver(bin_pkg,arch,ver);
281 CREATE INDEX bin_ver_src_ver_id_arch_idx ON bin_ver(src_ver,arch);
282 CREATE INDEX bin_ver_bin_pkg_id_idx ON bin_ver(bin_pkg);
283 CREATE INDEX bin_ver_src_ver_id_idx ON bin_ver(src_ver);
284 INSERT INTO table_comments VALUES ('bin_ver','Binary versions');
285 INSERT INTO column_comments VALUES ('bin_ver','id','Binary version id');
286 INSERT INTO column_comments VALUES ('bin_ver','bin_pkg','Binary package id (matches bin_pkg)');
287 INSERT INTO column_comments VALUES ('bin_ver','src_ver','Source version (matchines src_ver)');
288 INSERT INTO column_comments VALUES ('bin_ver','arch','Architecture id (matches arch)');
289 INSERT INTO column_comments VALUES ('bin_ver','ver','Binary version');
292 id SERIAL PRIMARY KEY,
293 tag TEXT NOT NULL UNIQUE,
294 obsolete BOOLEAN DEFAULT FALSE
296 INSERT INTO table_comments VALUES ('tag','Bug tags');
297 INSERT INTO column_comments VALUES ('tag','id','Tag id');
298 INSERT INTO column_comments VALUES ('tag','tag','Tag name');
299 INSERT INTO column_comments VALUES ('tag','obsolete','Whether a tag is obsolete (should not be set on new bugs)');
301 CREATE TABLE bug_tag (
302 bug INT NOT NULL REFERENCES bug,
303 tag INT NOT NULL REFERENCES tag
305 INSERT INTO table_comments VALUES ('bug_tag','Bug <-> tag mapping');
306 INSERT INTO column_comments VALUES ('bug_tag','bug','Bug id (matches bug)');
307 INSERT INTO column_comments VALUES ('bug_tag','tag','Tag id (matches tag)');
309 CREATE UNIQUE INDEX bug_tag_bug_tag ON bug_tag (bug,tag);
310 CREATE INDEX bug_tag_tag ON bug_tag (tag);
312 CREATE TABLE user_tag (
313 id SERIAL PRIMARY KEY,
315 correspondent INT NOT NULL REFERENCES correspondent(id)
317 INSERT INTO table_comments VALUES ('user_tag','User bug tags');
318 INSERT INTO column_comments VALUES ('user_tag','id','User bug tag id');
319 INSERT INTO column_comments VALUES ('user_tag','tag','User bug tag name');
320 INSERT INTO column_comments VALUES ('user_tag','correspondent','User bug tag correspondent');
322 CREATE UNIQUE INDEX user_tag_tag_correspondent ON user_tag(tag,correspondent);
323 CREATE INDEX user_tag_correspondent ON user_tag(correspondent);
325 CREATE TABLE bug_user_tag (
326 bug INT NOT NULL REFERENCES bug,
327 user_tag INT NOT NULL REFERENCES user_tag
329 INSERT INTO table_comments VALUES ('bug_user_tag','Bug <-> user tag mapping');
330 INSERT INTO column_comments VALUES ('bug_user_tag','bug','Bug id (matches bug)');
331 INSERT INTO column_comments VALUES ('bug_user_tag','tag','User tag id (matches user_tag)');
333 CREATE UNIQUE INDEX bug_user_tag_bug_tag ON bug_user_tag (bug,user_tag);
334 CREATE INDEX bug_user_tag_tag ON bug_user_tag (user_tag);
336 CREATE TABLE bug_binpackage (
337 bug INT NOT NULL REFERENCES bug,
338 bin_pkg INT NOT NULL REFERENCES bin_pkg ON UPDATE CASCADE ON DELETE CASCADE
340 CREATE UNIQUE INDEX bug_binpackage_id_pkg ON bug_binpackage(bug,bin_pkg);
341 INSERT INTO table_comments VALUES ('bug_binpackage','Bug <-> binary package mapping');
342 INSERT INTO column_comments VALUES ('bug_binpackage','bug','Bug id (matches bug)');
343 INSERT INTO column_comments VALUES ('bug_binpackage','bin_pkg','Binary package id (matches bin_pkg)');
345 CREATE TABLE bug_srcpackage (
346 bug INT NOT NULL REFERENCES bug,
347 src_pkg INT NOT NULL REFERENCES src_pkg ON UPDATE CASCADE ON DELETE CASCADE
349 CREATE UNIQUE INDEX bug_srcpackage_id_pkg ON bug_srcpackage(bug,src_pkg);
350 CREATE INDEX bug_srcpackage_idx_src_pkg ON bug_srcpackage(src_pkg);
352 INSERT INTO table_comments VALUES ('bug_srcpackage','Bug <-> source package mapping');
353 INSERT INTO column_comments VALUES ('bug_srcpackage','bug','Bug id (matches bug)');
354 INSERT INTO column_comments VALUES ('bug_srcpackage','src_pkg','Source package id (matches src_pkg)');
356 CREATE TABLE bug_affects_binpackage (
357 bug INT NOT NULL REFERENCES bug,
358 bin_pkg INT NOT NULL REFERENCES bin_pkg ON UPDATE CASCADE ON DELETE CASCADE
360 CREATE UNIQUE INDEX bug_affects_binpackage_id_pkg ON bug_affects_binpackage(bug,bin_pkg);
361 INSERT INTO table_comments VALUES ('bug_affects_binpackage','Bug <-> binary package mapping');
362 INSERT INTO column_comments VALUES ('bug_affects_binpackage','bug','Bug id (matches bug)');
363 INSERT INTO column_comments VALUES ('bug_affects_binpackage','bin_pkg','Binary package id (matches bin_pkg)');
365 CREATE TABLE bug_affects_srcpackage (
366 bug INT NOT NULL REFERENCES bug,
367 src_pkg INT NOT NULL REFERENCES src_pkg ON UPDATE CASCADE ON DELETE CASCADE
369 CREATE UNIQUE INDEX bug_affects_srcpackage_id_pkg ON bug_affects_srcpackage(bug,src_pkg);
370 INSERT INTO table_comments VALUES ('bug_affects_srcpackage','Bug <-> source package mapping');
371 INSERT INTO column_comments VALUES ('bug_affects_srcpackage','bug','Bug id (matches bug)');
372 INSERT INTO column_comments VALUES ('bug_affects_srcpackage','src_pkg','Source package id (matches src_pkg)');
374 CREATE VIEW bug_package (bug,pkg_id,pkg_type,package) AS
375 SELECT b.bug,b.bin_pkg,'binary',bp.pkg FROM bug_binpackage b JOIN bin_pkg bp ON bp.id=b.bin_pkg UNION
376 SELECT s.bug,s.src_pkg,'source',sp.pkg FROM bug_srcpackage s JOIN src_pkg sp ON sp.id=s.src_pkg UNION
377 SELECT b.bug,b.bin_pkg,'binary_affects',bp.pkg FROM bug_affects_binpackage b JOIN bin_pkg bp ON bp.id=b.bin_pkg UNION
378 SELECT s.bug,s.src_pkg,'source_affects',sp.pkg FROM bug_affects_srcpackage s JOIN src_pkg sp ON sp.id=s.src_pkg;
380 CREATE VIEW binary_versions (src_pkg, src_ver, bin_pkg, arch, bin_ver) AS
381 SELECT sp.pkg AS src_pkg, sv.ver AS src_ver, bp.pkg AS bin_pkg, a.arch AS arch, b.ver AS bin_ver,
382 svb.ver AS src_ver_based_on, spb.pkg AS src_pkg_based_on
383 FROM bin_ver b JOIN arch a ON b.arch = a.id
384 JOIN bin_pkg bp ON b.bin_pkg = bp.id
385 JOIN src_ver sv ON b.src_ver = sv.id
386 JOIN src_pkg sp ON sv.src_pkg = sp.id
387 LEFT OUTER JOIN src_ver svb ON sv.based_on = svb.id
388 LEFT OUTER JOIN src_pkg spb ON spb.id = svb.src_pkg;
391 id SERIAL PRIMARY KEY,
392 codename TEXT NOT NULL,
395 active BOOLEAN DEFAULT TRUE);
396 CREATE UNIQUE INDEX suite_idx_codename ON suite(codename);
397 CREATE UNIQUE INDEX suite_suite_name_key ON suite(suite_name);
398 CREATE UNIQUE INDEX suite_idx_version ON suite(version);
399 INSERT INTO table_comments VALUES ('suite','Debian Release Suite (stable, testing, etc.)');
400 INSERT INTO column_comments VALUES ('suite','id','Suite id');
401 INSERT INTO column_comments VALUES ('suite','suite_name','Suite name (testing, stable, etc.)');
402 INSERT INTO column_comments VALUES ('suite','version','Suite version; NULL if there is no appropriate version');
403 INSERT INTO column_comments VALUES ('suite','codename','Suite codename (sid, squeeze, etc.)');
404 INSERT INTO column_comments VALUES ('suite','active','TRUE if the suite is still accepting uploads');
406 CREATE TABLE bin_associations (
407 id SERIAL PRIMARY KEY,
408 suite INT NOT NULL REFERENCES suite ON DELETE CASCADE ON UPDATE CASCADE,
409 bin INT NOT NULL REFERENCES bin_ver ON DELETE CASCADE ON UPDATE CASCADE,
410 created TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
411 modified TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL
413 INSERT INTO table_comments VALUES ('bin_associations','Binary <-> suite associations');
414 INSERT INTO column_comments VALUES ('bin_associations','id','Binary <-> suite association id');
415 INSERT INTO column_comments VALUES ('bin_associations','suite','Suite id (matches suite)');
416 INSERT INTO column_comments VALUES ('bin_associations','bin','Binary version id (matches bin_ver)');
417 INSERT INTO column_comments VALUES ('bin_associations','created','Time this binary package entered this suite');
418 INSERT INTO column_comments VALUES ('bin_associations','modified','Time this entry was modified');
419 CREATE UNIQUE INDEX bin_associations_bin_suite ON bin_associations(bin,suite);
421 CREATE TABLE src_associations (
422 id SERIAL PRIMARY KEY,
423 suite INT NOT NULL REFERENCES suite ON DELETE CASCADE ON UPDATE CASCADE,
424 source INT NOT NULL REFERENCES src_ver ON DELETE CASCADE ON UPDATE CASCADE,
425 created TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
426 modified TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL
428 INSERT INTO table_comments VALUES ('src_associations','Source <-> suite associations');
429 INSERT INTO column_comments VALUES ('src_associations','id','Source <-> suite association id');
430 INSERT INTO column_comments VALUES ('src_associations','suite','Suite id (matches suite)');
431 INSERT INTO column_comments VALUES ('src_associations','source','Source version id (matches src_ver)');
432 INSERT INTO column_comments VALUES ('src_associations','created','Time this source package entered this suite');
433 INSERT INTO column_comments VALUES ('src_associations','modified','Time this entry was modified');
434 CREATE UNIQUE INDEX src_associations_source_suite ON src_associations(source,suite);
437 CREATE TYPE bug_status_type AS ENUM ('absent','found','fixed','undef');
438 CREATE TABLE bug_status_cache (
439 bug INT NOT NULL REFERENCES bug ON DELETE CASCADE ON UPDATE CASCADE,
440 suite INT REFERENCES suite ON DELETE CASCADE ON UPDATE CASCADE,
441 arch INT REFERENCES arch ON DELETE CASCADE ON UPDATE CASCADE,
442 status bug_status_type NOT NULL,
443 modified TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
444 asof TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL
446 CREATE UNIQUE INDEX bug_status_cache_bug_suite_arch_idx ON
447 bug_status_cache(bug,suite,arch);
448 CREATE UNIQUE INDEX bug_status_cache_bug_col_suite_col_arch_idx ON
449 bug_status_cache(bug,COALESCE(suite,0),COALESCE(arch,0));
450 CREATE INDEX bug_status_cache_idx_bug ON bug_status_cache(bug);
451 CREATE INDEX bug_status_cache_idx_status ON bug_status_cache(status);
452 CREATE INDEX bug_status_cache_idx_arch ON bug_status_cache(arch);
453 CREATE INDEX bug_status_cache_idx_suite ON bug_status_cache(suite);
454 CREATE INDEX bug_status_cache_idx_asof ON bug_status_cache(asof);
455 INSERT INTO table_comments VALUES ('bug_status_cache','Bug Status Cache');
456 INSERT INTO column_comments VALUES ('bug_status_cache','bug','Bug number (matches bug)');
457 INSERT INTO column_comments VALUES ('bug_status_cache','suite','Suite id (matches suite)');
458 INSERT INTO column_comments VALUES ('bug_status_cache','arch','Architecture id (matches arch)');
459 INSERT INTO column_comments VALUES ('bug_status_cache','status','Status (bug status)');
460 INSERT INTO column_comments VALUES ('bug_status_cache','modified','Time that this status was last modified');
461 INSERT INTO column_comments VALUES ('bug_status_cache','asof','Time that this status was last calculated');
465 CREATE TABLE message (
466 id SERIAL PRIMARY KEY,
467 msgid TEXT NOT NULL DEFAULT '',
468 from_complete TEXT NOT NULL DEFAULT '',
469 to_complete TEXT NOT NULL DEFAULT '',
470 subject TEXT NOT NULL DEFAULT '',
471 sent_date TIMESTAMP WITH TIME ZONE,
472 refs TEXT NOT NULL DEFAULT '',
473 spam_score FLOAT NOT NULL DEFAULT 0,
474 is_spam BOOLEAN NOT NULL DEFAULT FALSE
476 INSERT INTO table_comments VALUES ('message','Messages sent to bugs');
477 INSERT INTO column_comments VALUES ('message','id','Message id');
478 INSERT INTO column_comments VALUES ('message','msgid','Message id header');
479 INSERT INTO column_comments VALUES ('message','from_complete','Complete from header of message');
480 INSERT INTO column_comments VALUES ('message','to_complete','Complete to header of message');
481 INSERT INTO column_comments VALUES ('message','subject','Subject of the message');
482 INSERT INTO column_comments VALUES ('message','sent_date','Time/date message was sent (from Date header)');
483 INSERT INTO column_comments VALUES ('message','refs','Contents of References: header');
484 INSERT INTO column_comments VALUES ('message','spam_score','Spam score from spamassassin');
485 INSERT INTO column_comments VALUES ('message','is_spam','True if this message was spam and should not be shown');
486 CREATE INDEX message_msgid_idx ON message(msgid);
487 CREATE UNIQUE INDEX message_msgid_from_complete_to_complete_subject_idx
488 ON message(msgid,from_complete,to_complete,subject);
489 CREATE INDEX message_subject_idx ON message(subject);
491 CREATE TABLE message_refs (
492 message INT NOT NULL REFERENCES message ON DELETE CASCADE ON UPDATE CASCADE,
493 refs INT NOT NULL REFERENCES message ON DELETE CASCADE ON UPDATE CASCADE,
494 inferred BOOLEAN DEFAULT FALSE,
495 primary_ref BOOLEAN DEFAULT FALSE,
496 CONSTRAINT message_doesnt_reference_itself CHECK (message <> refs)
498 CREATE UNIQUE INDEX message_refs_message_refs_idx ON message_refs(message,refs);
499 CREATE INDEX message_refs_idx_refs ON message_refs(refs);
500 CREATE INDEX message_refs_idx_message ON message_refs(message);
501 INSERT INTO table_comments VALUES ('message_refs','Message references');
502 INSERT INTO column_comments VALUES ('message_refs','message','Message id (matches message)');
503 INSERT INTO column_comments VALUES ('message_refs','refs','Reference id (matches message)');
504 INSERT INTO column_comments VALUES ('message_refs','inferred','TRUE if this message reference was reconstructed; primarily of use for messages which lack In-Reply-To: or References: headers');
505 INSERT INTO column_comments VALUES ('message_refs','primary_ref','TRUE if this message->ref came from In-Reply-To: or similar.');
509 CREATE TABLE correspondent_full_name(
510 correspondent INT NOT NULL REFERENCES correspondent ON DELETE CASCADE ON UPDATE CASCADE,
511 full_name TEXT NOT NULL,
512 last_seen TIMESTAMP NOT NULL DEFAULT NOW()
514 CREATE UNIQUE INDEX correspondent_full_name_correspondent_full_name_idx
515 ON correspondent_full_name(correspondent,full_name);
516 CREATE INDEX correspondent_full_name_idx_full_name ON correspondent_full_name(full_name);
517 CREATE INDEX correspondent_full_name_idx_last_seen ON correspondent_full_name(last_seen);
518 INSERT INTO table_comments VALUES ('correspondent_full_name','Full names of BTS correspondents');
519 INSERT INTO column_comments VALUES ('correspondent_full_name','correspondent','Correspondent ID (matches correspondent)');
520 INSERT INTO column_comments VALUES ('correspondent_full_name','full_name','Correspondent full name (includes e-mail address)');
522 CREATE TYPE message_correspondent_type AS ENUM ('to','from','envfrom','cc','recv');
524 CREATE TABLE message_correspondent (
525 message INT NOT NULL REFERENCES message ON DELETE CASCADE ON UPDATE CASCADE,
526 correspondent INT NOT NULL REFERENCES correspondent ON DELETE CASCADE ON UPDATE CASCADE,
527 correspondent_type message_correspondent_type NOT NULL DEFAULT 'to'
529 INSERT INTO table_comments VALUES ('message_correspondent','Linkage between correspondent and message');
530 INSERT INTO column_comments VALUES ('message_correspondent','message','Message id (matches message)');
531 INSERT INTO column_comments VALUES ('message_correspondent','correspondent','Correspondent (matches correspondent)');
532 INSERT INTO column_comments VALUES ('message_correspondent','correspondent_type','Type of correspondent (to, from, envfrom, cc, etc.)');
534 CREATE UNIQUE INDEX message_correspondent_message_correspondent_correspondent_t_idx
535 ON message_correspondent(message,correspondent,correspondent_type);
536 CREATE INDEX message_correspondent_idx_correspondent ON message_correspondent(correspondent);
537 CREATE INDEX message_correspondent_idx_message ON message_correspondent(message);
539 CREATE TABLE bug_message (
540 bug INT NOT NULL REFERENCES bug ON DELETE CASCADE ON UPDATE CASCADE,
541 message INT NOT NULL REFERENCES message ON DELETE CASCADE ON UPDATE CASCADE,
542 message_number INT NOT NULL,
544 offset_valid TIMESTAMP WITH TIME ZONE
546 CREATE UNIQUE INDEX bug_message_bug_message_idx ON bug_message(bug,message);
547 CREATE INDEX bug_message_idx_bug_message_number ON bug_message(bug,message_number);
548 INSERT INTO table_comments VALUES ('bug_mesage','Mapping between a bug and a message');
549 INSERT INTO column_comments VALUES ('bug_message','bug','Bug id (matches bug)');
550 INSERT INTO column_comments VALUES ('bug_message','message','Message id (matches message)');
551 INSERT INTO column_comments VALUES ('bug_message','message_number','Message number in the bug log');
552 INSERT INTO column_comments VALUES ('bug_message','bug_log_offset','Byte offset in the bug log');
553 INSERT INTO column_comments VALUES ('bug_message','offset_valid','Time offset was valid');
555 CREATE VIEW bug_status --(id,bug_num,tags,subject,
556 -- severity,package,originator,log_modified,date,
557 -- last_modified, blocks, blockedby, mergedwith,
558 -- fixed_versions,found_versions)
562 string_agg(t.tag,',') AS tags,
563 b.subject AS subject,
564 (SELECT s.severity FROM severity s WHERE s.id=b.severity) AS severity,
565 (SELECT string_agg(package.package,',' ORDER BY package)
566 FROM (SELECT bp.pkg AS package
567 FROM bug_binpackage bbp
568 JOIN bin_pkg bp ON bbp.bin_pkg=bp.id
571 SELECT CONCAT('src:',sp.pkg) AS package
572 FROM bug_srcpackage bsp
573 JOIN src_pkg sp ON bsp.src_pkg=sp.id
574 WHERE bsp.bug=b.id) AS package
576 b.submitter_full AS originator,
577 EXTRACT(EPOCH FROM b.log_modified) AS log_modified,
578 EXTRACT(EPOCH FROM b.creation) AS date,
579 EXTRACT(EPOCH FROM b.last_modified) AS last_modified,
581 string_agg(bb.blocks::text,' ' ORDER BY bb.blocks) AS blocks,
582 string_agg(bbb.bug::text,' ' ORDER BY bbb.bug) AS blockedby,
583 (SELECT string_agg(bug.bug::text,' ' ORDER BY bug.bug)
584 FROM (SELECT bm.merged AS bug FROM bug_merged bm WHERE bm.bug=b.id
586 SELECT bm.bug AS bug FROM bug_merged bm WHERE bm.merged=b.id) AS bug) AS mergedwith,
587 (SELECT string_agg(bv.ver_string,' ') FROM bug_ver bv WHERE bv.bug=b.id AND bv.found IS TRUE)
589 (SELECT string_agg(bv.ver_string,' ') FROM bug_ver bv WHERE bv.bug=b.id AND bv.found IS FALSE)
592 LEFT JOIN bug_tag bt ON bt.bug=b.id
593 LEFT JOIN tag t ON bt.tag=t.id
594 LEFT JOIN bug_blocks bb ON bb.bug=b.id
595 LEFT JOIN bug_blocks bbb ON bbb.blocks=b.id