2 DROP TABLE bug_status_cache CASCADE;
3 DROP VIEW bug_package CASCADE;
4 DROP VIEW binary_versions CASCADE;
5 DROP TABLE bug_tag CASCADE;
6 DROP TABLE tag CASCADE;
7 DROP TABLE bug_user_tag CASCADE;
8 DROP TABLE user_tag CASCADE;
9 DROP TABLE severity CASCADE;
10 DROP TABLE bug CASCADE;
11 DROP TABLE src_pkg CASCADE;
12 DROP TABLE bug_ver CASCADE;
13 DROP TABLE src_ver CASCADE;
14 DROP TABLE arch CASCADE;
15 DROP TABLE bin_ver CASCADE;
16 DROP TABLE bin_pkg CASCADE;
17 DROP TABLE bug_blocks CASCADE;
18 DROP TABLE bug_merged CASCADE;
19 DROP TABLE bug_srcpackage CASCADE;
20 DROP TABLE bug_binpackage CASCADE;
21 DROP TABLE bug_affects_binpackage CASCADE;
22 DROP TABLE bug_affects_srcpackage CASCADE;
23 DROP TABLE suite CASCADE;
24 DROP TABLE bin_associations CASCADE;
25 DROP TABLE src_associations CASCADE;
26 DROP TABLE maintainer CASCADE;
27 DROP TABLE bug_message CASCADE;
28 DROP TABLE message_correspondent CASCADE;
29 DROP TABLE correspondent_full_name CASCADE;
30 DROP TABLE correspondent CASCADE;
31 DROP TABLE message_refs CASCADE;
32 DROP TABLE message CASCADE;
33 DROP TYPE message_correspondent_type CASCADE;
34 DROP TABLE table_comments CASCADE;
35 DROP TABLE column_comments CASCADE;
36 DROP TYPE bug_status_type CASCADE;
38 -- the following two tables are used to provide documentation about
39 -- the tables and columns for DBIx::Class::Schema::Loader
40 CREATE TABLE table_comments (
41 table_name TEXT NOT NULL,
42 comment_text TEXT NOT NULL
44 CREATE UNIQUE INDEX table_comments_table_name_idx ON table_comments(table_name);
45 CREATE TABLE column_comments (
46 table_name TEXT NOT NULL,
47 column_name TEXT NOT NULL,
48 comment_text TEXT NOT NULL
50 CREATE UNIQUE INDEX column_comments_table_name_column_name_idx ON column_comments(table_name,column_name);
53 CREATE TABLE correspondent (
54 id SERIAL PRIMARY KEY,
57 CREATE UNIQUE INDEX correspondent_addr_idx ON correspondent(addr);
58 INSERT INTO table_comments VALUES ('correspondent','Individual who has corresponded with the BTS');
59 INSERT INTO column_comments VALUES ('correspondent','id','Correspondent ID');
60 INSERT INTO column_comments VALUES ('correspondent','addr','Correspondent address');
62 CREATE TABLE maintainer (
63 id SERIAL PRIMARY KEY,
65 correspondent INT NOT NULL REFERENCES correspondent(id),
66 created TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
67 modified TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL
69 CREATE UNIQUE INDEX maintainer_name_idx ON maintainer(name);
70 CREATE INDEX maintainer_idx_correspondent ON maintainer(correspondent);
71 INSERT INTO table_comments VALUES ('maintainer','Package maintainer names');
72 INSERT INTO column_comments VALUES ('maintainer','id','Package maintainer id');
73 INSERT INTO column_comments VALUES ('maintainer','name','Name of package maintainer');
74 INSERT INTO column_comments VALUES ('maintainer','correspondent','Correspondent ID');
75 INSERT INTO column_comments VALUES ('maintainer','created','Time maintainer record created');
76 INSERT INTO column_comments VALUES ('maintainer','modified','Time maintainer record modified');
79 CREATE TABLE severity (
80 id SERIAL PRIMARY KEY,
81 severity TEXT NOT NULL,
82 ordering INT NOT NULL DEFAULT 5,
83 strong BOOLEAN DEFAULT FALSE,
84 obsolete BOOLEAN DEFAULT FALSE
86 CREATE UNIQUE INDEX severity_severity_idx ON severity(severity);
87 CREATE INDEX severity_ordering_idx ON severity(ordering);
88 INSERT INTO table_comments VALUES ('severity','Bug severity');
89 INSERT INTO column_comments VALUES ('severity','id','Severity id');
90 INSERT INTO column_comments VALUES ('severity','severity','Severity name');
91 INSERT INTO column_comments VALUES ('severity','ordering','Severity ordering (more severe severities have higher numbers)');
92 INSERT INTO column_comments VALUES ('severity','strong','True if severity is a strong severity');
93 INSERT INTO column_comments VALUES ('severity','obsolete','Whether a severity level is obsolete (should not be set on new bugs)');
97 id INTEGER NOT NULL PRIMARY KEY,
98 creation TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
99 log_modified TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
100 last_modified TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
101 archived BOOLEAN NOT NULL DEFAULT FALSE,
102 unarchived TIMESTAMP WITH TIME ZONE,
103 forwarded TEXT NOT NULL DEFAULT '',
104 summary TEXT NOT NULL DEFAULT '',
105 outlook TEXT NOT NULL DEFAULT '',
106 subject TEXT NOT NULL,
107 severity INT NOT NULL REFERENCES severity(id),
108 done INT REFERENCES correspondent(id),
109 done_full TEXT NOT NULL DEFAULT '',
110 owner INT REFERENCES correspondent(id),
111 owner_full TEXT NOT NULL DEFAULT '',
112 -- submitter would ideally be NOT NULL, but there are some ancient bugs which do not have submitters
113 submitter INT REFERENCES correspondent(id),
114 submitter_full TEXT NOT NULL DEFAULT '',
115 unknown_packages TEXT NOT NULL DEfAULT ''
117 CREATE INDEX bug_idx_owner ON bug(owner);
118 CREATE INDEX bug_idx_submitter ON bug(submitter);
119 CREATE INDEX bug_idx_done ON bug(done);
120 CREATE INDEX bug_idx_forwarded ON bug(forwarded);
121 CREATE INDEX bug_idx_last_modified ON bug(last_modified);
122 CREATE INDEX bug_idx_severity ON bug(severity);
123 CREATE INDEX bug_idx_creation ON bug(creation);
124 CREATE INDEX bug_idx_log_modified ON bug(log_modified);
126 INSERT INTO table_comments VALUES ('bug','Bugs');
127 INSERT INTO column_comments VALUES ('bug','id','Bug number');
128 INSERT INTO column_comments VALUES ('bug','creation','Time bug created');
129 INSERT INTO column_comments VALUES ('bug','log_modified','Time bug log was last modified');
130 INSERT INTO column_comments VALUES ('bug','last_modified','Time bug status was last modified');
131 INSERT INTO column_comments VALUES ('bug','archived','True if bug has been archived');
132 INSERT INTO column_comments VALUES ('bug','unarchived','Time bug was last unarchived; null if bug has never been unarchived');
133 INSERT INTO column_comments VALUES ('bug','forwarded','Where bug has been forwarded to; empty if it has not been forwarded');
134 INSERT INTO column_comments VALUES ('bug','summary','Summary of the bug; empty if it has no summary');
135 INSERT INTO column_comments VALUES ('bug','outlook','Outlook of the bug; empty if it has no outlook');
136 INSERT INTO column_comments VALUES ('bug','subject','Subject of the bug');
137 INSERT INTO column_comments VALUES ('bug','done','Individual who did the -done; empty if it has never been -done');
138 INSERT INTO column_comments VALUES ('bug','owner','Individual who owns this bug; empty if no one owns it');
139 INSERT INTO column_comments VALUES ('bug','submitter','Individual who submitted this bug; empty if there is no submitter');
140 INSERT INTO column_comments VALUES ('bug','unknown_packages','Package name if the package is not known');
144 CREATE TABLE bug_blocks (
145 id SERIAL PRIMARY KEY,
146 bug INT NOT NULL REFERENCES bug,
147 blocks INT NOT NULL REFERENCES bug,
148 CONSTRAINT bug_doesnt_block_itself CHECK (bug <> blocks)
150 CREATE UNIQUE INDEX bug_blocks_bug_id_blocks_idx ON bug_blocks(bug,blocks);
151 CREATE INDEX bug_blocks_bug_id_idx ON bug_blocks(bug);
152 CREATE INDEX bug_blocks_blocks_idx ON bug_blocks(blocks);
153 INSERT INTO table_comments VALUES ('bug_blocks','Bugs which block other bugs');
154 INSERT INTO column_comments VALUES ('bug_blocks','bug','Bug number');
155 INSERT INTO column_comments VALUES ('bug_blocks','blocks','Bug number which is blocked by bug');
158 CREATE TABLE bug_merged (
159 id SERIAL PRIMARY KEY,
160 bug INT NOT NULL REFERENCES bug,
161 merged INT NOT NULL REFERENCES bug,
162 CONSTRAINT bug_doesnt_merged_itself CHECK (bug <> merged)
164 CREATE UNIQUE INDEX bug_merged_bug_id_merged_idx ON bug_merged(bug,merged);
165 CREATE INDEX bug_merged_bug_id_idx ON bug_merged(bug);
166 CREATE INDEX bug_merged_merged_idx ON bug_merged(merged);
167 INSERT INTO table_comments VALUES ('bug_merged','Bugs which are merged with other bugs');
168 INSERT INTO column_comments VALUES ('bug_merged','bug','Bug number');
169 INSERT INTO column_comments VALUES ('bug_merged','merged','Bug number which is merged with bug');
171 CREATE TABLE src_pkg (
172 id SERIAL PRIMARY KEY,
174 pseduopkg BOOLEAN NOT NULL DEFAULT FALSE,
175 alias_of INT REFERENCES src_pkg ON UPDATE CASCADE ON DELETE CASCADE,
176 creation TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
177 disabled TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT 'infinity'::timestamp with time zone,
178 last_modified TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
179 obsolete BOOLEAN NOT NULL DEFAULT FALSE,
180 CONSTRAINT src_pkg_doesnt_alias_itself CHECK (id <> alias_of),
181 CONSTRAINT src_pkg_is_obsolete_if_disabled CHECK (
182 (obsolete IS FALSE AND disabled='infinity'::timestamp with time zone) OR
183 (obsolete IS TRUE AND disabled < 'infinity'::timestamp with time zone))
185 CREATE INDEX src_pkg_pkg ON src_pkg(pkg);
186 CREATE UNIQUE INDEX src_pkg_pkg_null ON src_pkg(pkg) WHERE disabled='infinity'::timestamp with time zone;
187 CREATE UNIQUE INDEX src_pkg_pkg_disabled ON src_pkg(pkg,disabled);
188 INSERT INTO table_comments VALUES ('src_pkg','Source packages');
189 INSERT INTO column_comments VALUES ('src_pkg','id','Source package id');
190 INSERT INTO column_comments VALUES ('src_pkg','pkg','Source package name');
191 INSERT INTO column_comments VALUES ('src_pkg','pseudopkg','True if this is a pseudo package');
192 INSERT INTO column_comments VALUES ('src_pkg','alias_of','Source package id which this source package is an alias of');
196 CREATE TABLE src_ver (
197 id SERIAL PRIMARY KEY,
198 src_pkg INT NOT NULL REFERENCES src_pkg
199 ON UPDATE CASCADE ON DELETE CASCADE,
200 ver debversion NOT NULL,
201 maintainer INT REFERENCES maintainer
202 ON UPDATE CASCADE ON DELETE SET NULL,
203 upload_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
204 based_on INT REFERENCES src_ver
205 ON UPDATE CASCADE ON DELETE CASCADE
207 CREATE UNIQUE INDEX src_ver_src_pkg_id_ver ON src_ver(src_pkg,ver);
208 INSERT INTO table_comments VALUES ('src_ver','Source Package versions');
209 INSERT INTO column_comments VALUES ('src_ver','id','Source package version id');
210 INSERT INTO column_comments VALUES ('src_ver','src_pkg','Source package id (matches src_pkg table)');
211 INSERT INTO column_comments VALUES ('src_ver','ver','Version of the source package');
212 INSERT INTO column_comments VALUES ('src_ver','maintainer','Maintainer id (matches maintainer table)');
213 INSERT INTO column_comments VALUES ('src_ver','upload_date','Date this version of the source package was uploaded');
214 INSERT INTO column_comments VALUES ('src_ver','based_on','Source package version this version is based on');
218 CREATE TABLE bug_ver (
219 id SERIAL PRIMARY KEY,
220 bug INT NOT NULL REFERENCES bug
221 ON UPDATE CASCADE ON DELETE RESTRICT,
223 src_pkg INT REFERENCES src_pkg
224 ON UPDATE CASCADE ON DELETE SET NULL,
225 src_ver INT REFERENCES src_ver
226 ON UPDATE CASCADE ON DELETE SET NULL,
227 found BOOLEAN NOT NULL DEFAULT TRUE,
228 creation TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
229 last_modified TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
231 CREATE INDEX bug_ver_src_pkg_id_idx ON bug_ver(src_pkg);
232 CREATE INDEX bug_ver_src_pkg_id_src_ver_id_idx ON bug_ver(src_pkg,src_ver);
233 CREATE INDEX bug_ver_src_ver_id_idx ON bug_ver(src_ver);
234 CREATE UNIQUE INDEX bug_ver_bug_ver_string_found_idx ON bug_ver(bug,ver_string,found);
235 INSERT INTO table_comments VALUES ('bug_ver','Bug versions');
236 INSERT INTO column_comments VALUES ('bug_ver','id','Bug version id');
237 INSERT INTO column_comments VALUES ('bug_ver','bug','Bug number');
238 INSERT INTO column_comments VALUES ('bug_ver','ver_string','Version string');
239 INSERT INTO column_comments VALUES ('bug_ver','src_pkg','Source package id (matches src_pkg table)');
240 INSERT INTO column_comments VALUES ('bug_ver','src_ver','Source package version id (matches src_ver table)');
241 INSERT INTO column_comments VALUES ('bug_ver','found','True if this is a found version; false if this is a fixed version');
242 INSERT INTO column_comments VALUES ('bug_ver','creation','Time that this entry was created');
243 INSERT INTO column_comments VALUES ('bug_ver','last_modified','Time that this entry was modified');
247 id SERIAL PRIMARY KEY,
250 CREATE UNIQUE INDEX arch_arch_key ON arch(arch);
251 INSERT INTO table_comments VALUES ('arch','Architectures');
252 INSERT INTO column_comments VALUES ('arch','id','Architecture id');
253 INSERT INTO column_comments VALUES ('arch','arch','Architecture name');
256 CREATE TABLE bin_pkg (
257 id SERIAL PRIMARY KEY,
260 CREATE UNIQUE INDEX bin_pkg_pkg_key ON bin_pkg(pkg);
261 INSERT INTO table_comments VALUES ('bin_pkg','Binary packages');
262 INSERT INTO column_comments VALUES ('bin_pkg','id','Binary package id');
263 INSERT INTO column_comments VALUES ('bin_pkg','pkg','Binary package name');
266 CREATE TABLE bin_ver(
267 id SERIAL PRIMARY KEY,
268 bin_pkg INT NOT NULL REFERENCES bin_pkg
269 ON UPDATE CASCADE ON DELETE CASCADE,
270 src_ver INT NOT NULL REFERENCES src_ver
271 ON UPDATE CASCADE ON DELETE CASCADE,
272 arch INT NOT NULL REFERENCES arch
273 ON UPDATE CASCADE ON DELETE CASCADE,
274 ver debversion NOT NULL
276 CREATE INDEX bin_ver_ver_idx ON bin_ver(ver);
277 CREATE UNIQUE INDEX bin_ver_bin_pkg_id_arch_idx ON bin_ver(bin_pkg,arch,ver);
278 CREATE INDEX bin_ver_src_ver_id_arch_idx ON bin_ver(src_ver,arch);
279 CREATE INDEX bin_ver_bin_pkg_id_idx ON bin_ver(bin_pkg);
280 CREATE INDEX bin_ver_src_ver_id_idx ON bin_ver(src_ver);
281 INSERT INTO table_comments VALUES ('bin_ver','Binary versions');
282 INSERT INTO column_comments VALUES ('bin_ver','id','Binary version id');
283 INSERT INTO column_comments VALUES ('bin_ver','bin_pkg','Binary package id (matches bin_pkg)');
284 INSERT INTO column_comments VALUES ('bin_ver','src_ver','Source version (matchines src_ver)');
285 INSERT INTO column_comments VALUES ('bin_ver','arch','Architecture id (matches arch)');
286 INSERT INTO column_comments VALUES ('bin_ver','ver','Binary version');
289 id SERIAL PRIMARY KEY,
290 tag TEXT NOT NULL UNIQUE,
291 obsolete BOOLEAN DEFAULT FALSE
293 INSERT INTO table_comments VALUES ('tag','Bug tags');
294 INSERT INTO column_comments VALUES ('tag','id','Tag id');
295 INSERT INTO column_comments VALUES ('tag','tag','Tag name');
296 INSERT INTO column_comments VALUES ('tag','obsolete','Whether a tag is obsolete (should not be set on new bugs)');
298 CREATE TABLE bug_tag (
299 bug INT NOT NULL REFERENCES bug,
300 tag INT NOT NULL REFERENCES tag
302 INSERT INTO table_comments VALUES ('bug_tag','Bug <-> tag mapping');
303 INSERT INTO column_comments VALUES ('bug_tag','bug','Bug id (matches bug)');
304 INSERT INTO column_comments VALUES ('bug_tag','tag','Tag id (matches tag)');
306 CREATE UNIQUE INDEX bug_tag_bug_tag ON bug_tag (bug,tag);
307 CREATE INDEX bug_tag_tag ON bug_tag (tag);
309 CREATE TABLE user_tag (
310 id SERIAL PRIMARY KEY,
312 correspondent INT NOT NULL REFERENCES correspondent(id)
314 INSERT INTO table_comments VALUES ('user_tag','User bug tags');
315 INSERT INTO column_comments VALUES ('user_tag','id','User bug tag id');
316 INSERT INTO column_comments VALUES ('user_tag','tag','User bug tag name');
317 INSERT INTO column_comments VALUES ('user_tag','correspondent','User bug tag correspondent');
319 CREATE UNIQUE INDEX user_tag_tag_correspondent ON user_tag(tag,correspondent);
320 CREATE INDEX user_tag_correspondent ON user_tag(correspondent);
322 CREATE TABLE bug_user_tag (
323 bug INT NOT NULL REFERENCES bug,
324 user_tag INT NOT NULL REFERENCES user_tag
326 INSERT INTO table_comments VALUES ('bug_user_tag','Bug <-> user tag mapping');
327 INSERT INTO column_comments VALUES ('bug_user_tag','bug','Bug id (matches bug)');
328 INSERT INTO column_comments VALUES ('bug_user_tag','tag','User tag id (matches user_tag)');
330 CREATE UNIQUE INDEX bug_user_tag_bug_tag ON bug_user_tag (bug,user_tag);
331 CREATE INDEX bug_user_tag_tag ON bug_user_tag (user_tag);
333 CREATE TABLE bug_binpackage (
334 bug INT NOT NULL REFERENCES bug,
335 bin_pkg INT NOT NULL REFERENCES bin_pkg ON UPDATE CASCADE ON DELETE CASCADE
337 CREATE UNIQUE INDEX bug_binpackage_id_pkg ON bug_binpackage(bug,bin_pkg);
338 INSERT INTO table_comments VALUES ('bug_binpackage','Bug <-> binary package mapping');
339 INSERT INTO column_comments VALUES ('bug_binpackage','bug','Bug id (matches bug)');
340 INSERT INTO column_comments VALUES ('bug_binpackage','bin_pkg','Binary package id (matches bin_pkg)');
342 CREATE TABLE bug_srcpackage (
343 bug INT NOT NULL REFERENCES bug,
344 src_pkg INT NOT NULL REFERENCES src_pkg ON UPDATE CASCADE ON DELETE CASCADE
346 CREATE UNIQUE INDEX bug_srcpackage_id_pkg ON bug_srcpackage(bug,src_pkg);
347 CREATE INDEX bug_srcpackage_idx_src_pkg ON bug_srcpackage(src_pkg);
349 INSERT INTO table_comments VALUES ('bug_srcpackage','Bug <-> source package mapping');
350 INSERT INTO column_comments VALUES ('bug_srcpackage','bug','Bug id (matches bug)');
351 INSERT INTO column_comments VALUES ('bug_srcpackage','src_pkg','Source package id (matches src_pkg)');
353 CREATE TABLE bug_affects_binpackage (
354 bug INT NOT NULL REFERENCES bug,
355 bin_pkg INT NOT NULL REFERENCES bin_pkg ON UPDATE CASCADE ON DELETE CASCADE
357 CREATE UNIQUE INDEX bug_affects_binpackage_id_pkg ON bug_affects_binpackage(bug,bin_pkg);
358 INSERT INTO table_comments VALUES ('bug_affects_binpackage','Bug <-> binary package mapping');
359 INSERT INTO column_comments VALUES ('bug_affects_binpackage','bug','Bug id (matches bug)');
360 INSERT INTO column_comments VALUES ('bug_affects_binpackage','bin_pkg','Binary package id (matches bin_pkg)');
362 CREATE TABLE bug_affects_srcpackage (
363 bug INT NOT NULL REFERENCES bug,
364 src_pkg INT NOT NULL REFERENCES src_pkg ON UPDATE CASCADE ON DELETE CASCADE
366 CREATE UNIQUE INDEX bug_affects_srcpackage_id_pkg ON bug_affects_srcpackage(bug,src_pkg);
367 INSERT INTO table_comments VALUES ('bug_affects_srcpackage','Bug <-> source package mapping');
368 INSERT INTO column_comments VALUES ('bug_affects_srcpackage','bug','Bug id (matches bug)');
369 INSERT INTO column_comments VALUES ('bug_affects_srcpackage','src_pkg','Source package id (matches src_pkg)');
371 CREATE VIEW bug_package (bug,pkg_id,pkg_type,package) AS
372 SELECT b.bug,b.bin_pkg,'binary',bp.pkg FROM bug_binpackage b JOIN bin_pkg bp ON bp.id=b.bin_pkg UNION
373 SELECT s.bug,s.src_pkg,'source',sp.pkg FROM bug_srcpackage s JOIN src_pkg sp ON sp.id=s.src_pkg UNION
374 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
375 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;
377 CREATE VIEW binary_versions (src_pkg, src_ver, bin_pkg, arch, bin_ver) AS
378 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,
379 svb.ver AS src_ver_based_on, spb.pkg AS src_pkg_based_on
380 FROM bin_ver b JOIN arch a ON b.arch = a.id
381 JOIN bin_pkg bp ON b.bin_pkg = bp.id
382 JOIN src_ver sv ON b.src_ver = sv.id
383 JOIN src_pkg sp ON sv.src_pkg = sp.id
384 LEFT OUTER JOIN src_ver svb ON sv.based_on = svb.id
385 LEFT OUTER JOIN src_pkg spb ON spb.id = svb.src_pkg;
388 id SERIAL PRIMARY KEY,
389 codename TEXT NOT NULL,
392 active BOOLEAN DEFAULT TRUE);
393 CREATE UNIQUE INDEX suite_idx_codename ON suite(codename);
394 CREATE UNIQUE INDEX suite_suite_name_key ON suite(suite_name);
395 CREATE UNIQUE INDEX suite_idx_version ON suite(version);
396 INSERT INTO table_comments VALUES ('suite','Debian Release Suite (stable, testing, etc.)');
397 INSERT INTO column_comments VALUES ('suite','id','Suite id');
398 INSERT INTO column_comments VALUES ('suite','suite_name','Suite name (testing, stable, etc.)');
399 INSERT INTO column_comments VALUES ('suite','version','Suite version; NULL if there is no appropriate version');
400 INSERT INTO column_comments VALUES ('suite','codename','Suite codename (sid, squeeze, etc.)');
401 INSERT INTO column_comments VALUES ('suite','active','TRUE if the suite is still accepting uploads');
403 CREATE TABLE bin_associations (
404 id SERIAL PRIMARY KEY,
405 suite INT NOT NULL REFERENCES suite ON DELETE CASCADE ON UPDATE CASCADE,
406 bin INT NOT NULL REFERENCES bin_ver ON DELETE CASCADE ON UPDATE CASCADE,
407 created TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
408 modified TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL
410 INSERT INTO table_comments VALUES ('bin_associations','Binary <-> suite associations');
411 INSERT INTO column_comments VALUES ('bin_associations','id','Binary <-> suite association id');
412 INSERT INTO column_comments VALUES ('bin_associations','suite','Suite id (matches suite)');
413 INSERT INTO column_comments VALUES ('bin_associations','bin','Binary version id (matches bin_ver)');
414 INSERT INTO column_comments VALUES ('bin_associations','created','Time this binary package entered this suite');
415 INSERT INTO column_comments VALUES ('bin_associations','modified','Time this entry was modified');
416 CREATE UNIQUE INDEX bin_associations_bin_suite ON bin_associations(bin,suite);
418 CREATE TABLE src_associations (
419 id SERIAL PRIMARY KEY,
420 suite INT NOT NULL REFERENCES suite ON DELETE CASCADE ON UPDATE CASCADE,
421 source INT NOT NULL REFERENCES src_ver ON DELETE CASCADE ON UPDATE CASCADE,
422 created TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
423 modified TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL
425 INSERT INTO table_comments VALUES ('src_associations','Source <-> suite associations');
426 INSERT INTO column_comments VALUES ('src_associations','id','Source <-> suite association id');
427 INSERT INTO column_comments VALUES ('src_associations','suite','Suite id (matches suite)');
428 INSERT INTO column_comments VALUES ('src_associations','source','Source version id (matches src_ver)');
429 INSERT INTO column_comments VALUES ('src_associations','created','Time this source package entered this suite');
430 INSERT INTO column_comments VALUES ('src_associations','modified','Time this entry was modified');
431 CREATE UNIQUE INDEX src_associations_source_suite ON src_associations(source,suite);
434 CREATE TYPE bug_status_type AS ENUM ('absent','found','fixed','undef');
435 CREATE TABLE bug_status_cache (
436 bug INT NOT NULL REFERENCES bug ON DELETE CASCADE ON UPDATE CASCADE,
437 suite INT REFERENCES suite ON DELETE CASCADE ON UPDATE CASCADE,
438 arch INT REFERENCES arch ON DELETE CASCADE ON UPDATE CASCADE,
439 status bug_status_type NOT NULL,
440 modified TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
441 asof TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL
443 CREATE UNIQUE INDEX bug_status_cache_bug_suite_arch_idx ON bug_status_cache(bug,suite,arch);
444 CREATE INDEX bug_status_cache_idx_bug ON bug_status_cache(bug);
445 CREATE INDEX bug_status_cache_idx_status ON bug_status_cache(status);
446 CREATE INDEX bug_status_cache_idx_arch ON bug_status_cache(arch);
447 CREATE INDEX bug_status_cache_idx_suite ON bug_status_cache(suite);
448 CREATE INDEX bug_status_cache_idx_asof ON bug_status_cache(asof);
449 INSERT INTO table_comments VALUES ('bug_status_cache','Bug Status Cache');
450 INSERT INTO column_comments VALUES ('bug_status_cache','bug','Bug number (matches bug)');
451 INSERT INTO column_comments VALUES ('bug_status_cache','suite','Suite id (matches suite)');
452 INSERT INTO column_comments VALUES ('bug_status_cache','arch','Architecture id (matches arch)');
453 INSERT INTO column_comments VALUES ('bug_status_cache','status','Status (bug status)');
454 INSERT INTO column_comments VALUES ('bug_status_cache','modified','Time that this status was last modified');
455 INSERT INTO column_comments VALUES ('bug_status_cache','asof','Time that this status was last calculated');
459 CREATE TABLE message (
460 id SERIAL PRIMARY KEY,
461 msgid TEXT NOT NULL DEFAULT '',
462 from_complete TEXT NOT NULL DEFAULT '',
463 to_complete TEXT NOT NULL DEFAULT '',
464 subject TEXT NOT NULL DEFAULT '',
465 sent_date TIMESTAMP WITH TIME ZONE,
466 refs TEXT NOT NULL DEFAULT '',
467 spam_score FLOAT NOT NULL DEFAULT 0,
468 is_spam BOOLEAN NOT NULL DEFAULT FALSE
470 INSERT INTO table_comments VALUES ('message','Messages sent to bugs');
471 INSERT INTO column_comments VALUES ('message','id','Message id');
472 INSERT INTO column_comments VALUES ('message','msgid','Message id header');
473 INSERT INTO column_comments VALUES ('message','from_complete','Complete from header of message');
474 INSERT INTO column_comments VALUES ('message','to_complete','Complete to header of message');
475 INSERT INTO column_comments VALUES ('message','subject','Subject of the message');
476 INSERT INTO column_comments VALUES ('message','sent_date','Time/date message was sent (from Date header)');
477 INSERT INTO column_comments VALUES ('message','refs','Contents of References: header');
478 INSERT INTO column_comments VALUES ('message','spam_score','Spam score from spamassassin');
479 INSERT INTO column_comments VALUES ('message','is_spam','True if this message was spam and should not be shown');
480 CREATE INDEX message_msgid_idx ON message(msgid);
481 CREATE UNIQUE INDEX message_msgid_from_complete_to_complete_subject_idx
482 ON message(msgid,from_complete,to_complete,subject);
483 CREATE INDEX message_subject_idx ON message(subject);
485 CREATE TABLE message_refs (
486 message INT NOT NULL REFERENCES message ON DELETE CASCADE ON UPDATE CASCADE,
487 refs INT NOT NULL REFERENCES message ON DELETE CASCADE ON UPDATE CASCADE,
488 inferred BOOLEAN DEFAULT FALSE,
489 primary_ref BOOLEAN DEFAULT FALSE,
490 CONSTRAINT message_doesnt_reference_itself CHECK (message <> refs)
492 CREATE UNIQUE INDEX message_refs_message_refs_idx ON message_refs(message,refs);
493 CREATE INDEX message_refs_idx_refs ON message_refs(refs);
494 CREATE INDEX message_refs_idx_message ON message_refs(message);
495 INSERT INTO table_comments VALUES ('message_refs','Message references');
496 INSERT INTO column_comments VALUES ('message_refs','message','Message id (matches message)');
497 INSERT INTO column_comments VALUES ('message_refs','refs','Reference id (matches message)');
498 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');
499 INSERT INTO column_comments VALUES ('message_refs','primary_ref','TRUE if this message->ref came from In-Reply-To: or similar.');
503 CREATE TABLE correspondent_full_name(
504 correspondent INT NOT NULL REFERENCES correspondent ON DELETE CASCADE ON UPDATE CASCADE,
505 full_name TEXT NOT NULL,
506 last_seen TIMESTAMP NOT NULL DEFAULT NOW()
508 CREATE UNIQUE INDEX correspondent_full_name_correspondent_full_name_idx
509 ON correspondent_full_name(correspondent,full_name);
510 CREATE INDEX correspondent_full_name_idx_full_name ON correspondent_full_name(full_name);
511 CREATE INDEX correspondent_full_name_idx_last_seen ON correspondent_full_name(last_seen);
512 INSERT INTO table_comments VALUES ('correspondent_full_name','Full names of BTS correspondents');
513 INSERT INTO column_comments VALUES ('correspondent_full_name','correspondent','Correspondent ID (matches correspondent)');
514 INSERT INTO column_comments VALUES ('correspondent_full_name','full_name','Correspondent full name (includes e-mail address)');
516 CREATE TYPE message_correspondent_type AS ENUM ('to','from','envfrom','cc','recv');
518 CREATE TABLE message_correspondent (
519 message INT NOT NULL REFERENCES message ON DELETE CASCADE ON UPDATE CASCADE,
520 correspondent INT NOT NULL REFERENCES correspondent ON DELETE CASCADE ON UPDATE CASCADE,
521 correspondent_type message_correspondent_type NOT NULL DEFAULT 'to'
523 INSERT INTO table_comments VALUES ('message_correspondent','Linkage between correspondent and message');
524 INSERT INTO column_comments VALUES ('message_correspondent','message','Message id (matches message)');
525 INSERT INTO column_comments VALUES ('message_correspondent','correspondent','Correspondent (matches correspondent)');
526 INSERT INTO column_comments VALUES ('message_correspondent','correspondent_type','Type of correspondent (to, from, envfrom, cc, etc.)');
528 CREATE UNIQUE INDEX message_correspondent_message_correspondent_correspondent_t_idx
529 ON message_correspondent(message,correspondent,correspondent_type);
530 CREATE INDEX message_correspondent_idx_correspondent ON message_correspondent(correspondent);
531 CREATE INDEX message_correspondent_idx_message ON message_correspondent(message);
533 CREATE TABLE bug_message (
534 bug INT NOT NULL REFERENCES bug ON DELETE CASCADE ON UPDATE CASCADE,
535 message INT NOT NULL REFERENCES message ON DELETE CASCADE ON UPDATE CASCADE,
536 message_number INT NOT NULL,
538 offset_valid TIMESTAMP WITH TIME ZONE
540 CREATE UNIQUE INDEX bug_message_bug_message_idx ON bug_message(bug,message);
541 CREATE INDEX bug_message_idx_bug_message_number ON bug_message(bug,message_number);
542 INSERT INTO table_comments VALUES ('bug_mesage','Mapping between a bug and a message');
543 INSERT INTO column_comments VALUES ('bug_message','bug','Bug id (matches bug)');
544 INSERT INTO column_comments VALUES ('bug_message','message','Message id (matches message)');
545 INSERT INTO column_comments VALUES ('bug_message','message_number','Message number in the bug log');
546 INSERT INTO column_comments VALUES ('bug_message','bug_log_offset','Byte offset in the bug log');
547 INSERT INTO column_comments VALUES ('bug_message','offset_valid','Time offset was valid');