X-Git-Url: https://git.donarmstrong.com/?a=blobdiff_plain;f=sql%2Fdebbugs_schema.sql;h=3a75bac8b3b7af8767e3349461fd45c347535954;hb=b1252b6797aa6a79d00a32165fb2fa8fb1bd9318;hp=7779a3574986fcfb2c470daf0716e9d2576d637c;hpb=c9782a782be1f388b3dcbf15dc86f3123815384f;p=debbugs.git diff --git a/sql/debbugs_schema.sql b/sql/debbugs_schema.sql index 7779a35..3a75bac 100644 --- a/sql/debbugs_schema.sql +++ b/sql/debbugs_schema.sql @@ -1,7 +1,8 @@ - +-- -*- mode: sql; sql-product: postgres; -*- DROP TABLE bug_status_cache CASCADE; DROP VIEW bug_package CASCADE; DROP VIEW binary_versions CASCADE; +DROP VIEW bug_status CASCADE; DROP TABLE bug_tag CASCADE; DROP TABLE tag CASCADE; DROP TABLE bug_user_tag CASCADE; @@ -112,7 +113,8 @@ CREATE TABLE bug ( -- submitter would ideally be NOT NULL, but there are some ancient bugs which do not have submitters submitter INT REFERENCES correspondent(id), submitter_full TEXT NOT NULL DEFAULT '', - unknown_packages TEXT NOT NULL DEfAULT '' + unknown_packages TEXT NOT NULL DEFAULT '', + unknown_affects TEXT NOT NULL DEFAULT '' ); CREATE INDEX bug_idx_owner ON bug(owner); CREATE INDEX bug_idx_submitter ON bug(submitter); @@ -138,6 +140,7 @@ INSERT INTO column_comments VALUES ('bug','done','Individual who did the -done; INSERT INTO column_comments VALUES ('bug','owner','Individual who owns this bug; empty if no one owns it'); INSERT INTO column_comments VALUES ('bug','submitter','Individual who submitted this bug; empty if there is no submitter'); INSERT INTO column_comments VALUES ('bug','unknown_packages','Package name if the package is not known'); +INSERT INTO column_comments VALUES ('bug','unknown_affects','Package name if the affected package is not known'); @@ -285,6 +288,74 @@ INSERT INTO column_comments VALUES ('bin_ver','src_ver','Source version (matchin INSERT INTO column_comments VALUES ('bin_ver','arch','Architecture id (matches arch)'); INSERT INTO column_comments VALUES ('bin_ver','ver','Binary version'); +CREATE TABLE bin_pkg_src_pkg ( + bin_pkg INT NOT NULL REFERENCES bin_pkg ON UPDATE CASCADE ON DELETE CASCADE, + src_pkg INT NOT NULL REFERENCES src_pkg ON UPDATE CASCADE ON DELETE CASCADE +); +CREATE UNIQUE INDEX bin_pkg_src_pkg_bin_pkg_src_pkg ON bin_pkg_src_pkg (bin_pkg,src_pkg); +CREATE UNIQUE INDEX bin_pkg_src_pkg_src_pkg_bin_pkg ON bin_pkg_src_pkg (src_pkg,bin_pkg); + + +INSERT INTO table_comments VALUES ('bin_pkg_src_pkg', + 'Binary package <-> source package mapping sumpmary table'); +INSERT INTO column_comments VALUES ('bin_pkg_src_pkg','bin_pkg','Binary package id (matches bin_pkg)'); +INSERT INTO column_comments VALUES ('bin_pkg_src_pkg','src_pkg','Source package id (matches src_pkg)'); + +CREATE OR REPLACE FUNCTION bin_ver_to_src_pkg(bin_ver INT) RETURNS INT + AS $src_pkg_from_bin_ver$ + DECLARE + src_pkg int; + BEGIN + SELECT sv.src_pkg INTO STRICT src_pkg + FROM bin_ver bv JOIN src_ver sv ON bv.src_ver=sv.id + WHERE bv.id=bin_ver; + RETURN src_pkg; + END + $src_pkg_from_bin_ver$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION src_ver_to_src_pkg(src_ver INT) RETURNS INT + AS $src_ver_to_src_pkg$ + DECLARE + src_pkg int; + BEGIN + SELECT sv.src_pkg INTO STRICT src_pkg + FROM src_ver sv WHERE sv.id=src_ver; + RETURN src_pkg; + END + $src_ver_to_src_pkg$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION update_bin_pkg_src_pkg_bin_ver () RETURNS TRIGGER + AS $update_bin_pkg_src_pkg_bin_ver$ + DECLARE + src_ver_rows integer; + BEGIN + IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE' ) THEN + -- if there is still a bin_ver with this src_pkg, then do nothing + PERFORM * FROM bin_ver bv JOIN src_ver sv ON bv.src_ver = sv.id + WHERE sv.id = OLD.src_ver LIMIT 2; + GET DIAGNOSTICS src_ver_rows = ROW_COUNT; + IF (src_ver_rows <= 1) THEN + DELETE FROM bin_pkg_src_pkg + WHERE bin_pkg=OLD.bin_pkg AND + src_pkg=src_ver_to_src_pkg(OLD.src_ver); + END IF; + END IF; + IF (TG_OP = 'INSERT' OR TG_OP = 'UPDATE') THEN + BEGIN + INSERT INTO bin_pkg_src_pkg (bin_pkg,src_pkg) + VALUES (NEW.bin_pkg,src_ver_to_src_pkg(NEW.src_ver)) + ON CONFLICT (bin_pkg,src_pkg) DO NOTHING; + END; + END IF; + RETURN NULL; + END + $update_bin_pkg_src_pkg_bin_ver$ LANGUAGE plpgsql; + +CREATE TRIGGER bin_ver_update_bin_pkg_src_pkg +AFTER INSERT OR UPDATE OR DELETE ON bin_ver +FOR EACH ROW EXECUTE PROCEDURE update_bin_pkg_src_pkg_bin_ver(); + + CREATE TABLE tag ( id SERIAL PRIMARY KEY, tag TEXT NOT NULL UNIQUE, @@ -335,6 +406,7 @@ CREATE TABLE bug_binpackage ( bin_pkg INT NOT NULL REFERENCES bin_pkg ON UPDATE CASCADE ON DELETE CASCADE ); CREATE UNIQUE INDEX bug_binpackage_id_pkg ON bug_binpackage(bug,bin_pkg); +CREATE UNIQUE INDEX bug_binpackage_bin_pkg_bug_idx ON bug_binpackage(bin_pkg,bug); INSERT INTO table_comments VALUES ('bug_binpackage','Bug <-> binary package mapping'); INSERT INTO column_comments VALUES ('bug_binpackage','bug','Bug id (matches bug)'); INSERT INTO column_comments VALUES ('bug_binpackage','bin_pkg','Binary package id (matches bin_pkg)'); @@ -350,10 +422,6 @@ INSERT INTO table_comments VALUES ('bug_srcpackage','Bug <-> source package mapp INSERT INTO column_comments VALUES ('bug_srcpackage','bug','Bug id (matches bug)'); INSERT INTO column_comments VALUES ('bug_srcpackage','src_pkg','Source package id (matches src_pkg)'); -CREATE VIEW bug_package (bug,pkg_id,pkg_type,package) AS - SELECT b.bug,b.bin_pkg,'binary',bp.pkg FROM bug_binpackage b JOIN bin_pkg bp ON bp.id=b.bin_pkg UNION - SELECT s.bug,s.src_pkg,'source',sp.pkg FROM bug_srcpackage s JOIN src_pkg sp ON sp.id=s.src_pkg; - CREATE TABLE bug_affects_binpackage ( bug INT NOT NULL REFERENCES bug, bin_pkg INT NOT NULL REFERENCES bin_pkg ON UPDATE CASCADE ON DELETE CASCADE @@ -372,6 +440,12 @@ INSERT INTO table_comments VALUES ('bug_affects_srcpackage','Bug <-> source pack INSERT INTO column_comments VALUES ('bug_affects_srcpackage','bug','Bug id (matches bug)'); INSERT INTO column_comments VALUES ('bug_affects_srcpackage','src_pkg','Source package id (matches src_pkg)'); +CREATE VIEW bug_package (bug,pkg_id,pkg_type,package) AS + SELECT b.bug,b.bin_pkg,'binary',bp.pkg FROM bug_binpackage b JOIN bin_pkg bp ON bp.id=b.bin_pkg UNION + SELECT s.bug,s.src_pkg,'source',sp.pkg FROM bug_srcpackage s JOIN src_pkg sp ON sp.id=s.src_pkg UNION + 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 + 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; + CREATE VIEW binary_versions (src_pkg, src_ver, bin_pkg, arch, bin_ver) AS 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, svb.ver AS src_ver_based_on, spb.pkg AS src_pkg_based_on @@ -429,7 +503,7 @@ INSERT INTO column_comments VALUES ('src_associations','modified','Time this ent CREATE UNIQUE INDEX src_associations_source_suite ON src_associations(source,suite); -CREATE TYPE bug_status_type AS ENUM ('pending','forwarded','pending-fixed','fixed','absent','done'); +CREATE TYPE bug_status_type AS ENUM ('absent','found','fixed','undef'); CREATE TABLE bug_status_cache ( bug INT NOT NULL REFERENCES bug ON DELETE CASCADE ON UPDATE CASCADE, suite INT REFERENCES suite ON DELETE CASCADE ON UPDATE CASCADE, @@ -438,13 +512,16 @@ CREATE TABLE bug_status_cache ( modified TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL, asof TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL ); -CREATE UNIQUE INDEX bug_status_cache_bug_suite_arch_idx ON bug_status_cache(bug,suite,arch); +CREATE UNIQUE INDEX bug_status_cache_bug_suite_arch_idx ON + bug_status_cache(bug,suite,arch); +CREATE UNIQUE INDEX bug_status_cache_bug_col_suite_col_arch_idx ON + bug_status_cache(bug,COALESCE(suite,0),COALESCE(arch,0)); CREATE INDEX bug_status_cache_idx_bug ON bug_status_cache(bug); CREATE INDEX bug_status_cache_idx_status ON bug_status_cache(status); CREATE INDEX bug_status_cache_idx_arch ON bug_status_cache(arch); CREATE INDEX bug_status_cache_idx_suite ON bug_status_cache(suite); +CREATE INDEX bug_status_cache_idx_asof ON bug_status_cache(asof); INSERT INTO table_comments VALUES ('bug_status_cache','Bug Status Cache'); -INSERT INTO column_comments VALUES ('bug_status_cache','id','Bug status cache entry id'); INSERT INTO column_comments VALUES ('bug_status_cache','bug','Bug number (matches bug)'); INSERT INTO column_comments VALUES ('bug_status_cache','suite','Suite id (matches suite)'); INSERT INTO column_comments VALUES ('bug_status_cache','arch','Architecture id (matches arch)'); @@ -499,7 +576,6 @@ INSERT INTO column_comments VALUES ('message_refs','primary_ref','TRUE if this m CREATE TABLE correspondent_full_name( - id SERIAL PRIMARY KEY, correspondent INT NOT NULL REFERENCES correspondent ON DELETE CASCADE ON UPDATE CASCADE, full_name TEXT NOT NULL, last_seen TIMESTAMP NOT NULL DEFAULT NOW() @@ -509,11 +585,10 @@ CREATE UNIQUE INDEX correspondent_full_name_correspondent_full_name_idx CREATE INDEX correspondent_full_name_idx_full_name ON correspondent_full_name(full_name); CREATE INDEX correspondent_full_name_idx_last_seen ON correspondent_full_name(last_seen); INSERT INTO table_comments VALUES ('correspondent_full_name','Full names of BTS correspondents'); -INSERT INTO column_comments VALUES ('correspondent_full_name','id','Correspondent full name id'); -INSERT INTO column_comments VALUES ('correspondent_full_name','correpsondent','Correspondent ID (matches correspondent)'); +INSERT INTO column_comments VALUES ('correspondent_full_name','correspondent','Correspondent ID (matches correspondent)'); INSERT INTO column_comments VALUES ('correspondent_full_name','full_name','Correspondent full name (includes e-mail address)'); -CREATE TYPE message_correspondent_type AS ENUM ('to','from','envfrom','cc'); +CREATE TYPE message_correspondent_type AS ENUM ('to','from','envfrom','cc','recv'); CREATE TABLE message_correspondent ( message INT NOT NULL REFERENCES message ON DELETE CASCADE ON UPDATE CASCADE, @@ -546,3 +621,58 @@ INSERT INTO column_comments VALUES ('bug_message','message_number','Message numb INSERT INTO column_comments VALUES ('bug_message','bug_log_offset','Byte offset in the bug log'); INSERT INTO column_comments VALUES ('bug_message','offset_valid','Time offset was valid'); +CREATE VIEW bug_status --(id,bug_num,tags,subject, +-- severity,package,originator,log_modified,date, +-- last_modified, blocks, blockedby, mergedwith, +-- fixed_versions,found_versions) + AS + SELECT b.id AS id, + b.id AS bug_num, + string_agg(t.tag,',') AS tags, + b.subject AS subject, + (SELECT s.severity FROM severity s WHERE s.id=b.severity) AS severity, + (SELECT string_agg(package.package,',' ORDER BY package) + FROM (SELECT bp.pkg AS package + FROM bug_binpackage bbp + JOIN bin_pkg bp ON bbp.bin_pkg=bp.id + WHERE bbp.bug=b.id + UNION + SELECT CONCAT('src:',sp.pkg) AS package + FROM bug_srcpackage bsp + JOIN src_pkg sp ON bsp.src_pkg=sp.id + WHERE bsp.bug=b.id) AS package + ) AS package, + (SELECT string_agg(affects.affects,',' ORDER BY affects) + FROM (SELECT bp.pkg AS affects + FROM bug_affects_binpackage bbp + JOIN bin_pkg bp ON bbp.bin_pkg=bp.id + WHERE bbp.bug=b.id + UNION + SELECT CONCAT('src:',sp.pkg) AS affects + FROM bug_affects_srcpackage bsp + JOIN src_pkg sp ON bsp.src_pkg=sp.id + WHERE bsp.bug=b.id) AS affects + ) AS affects, + (SELECT msgid FROM message m LEFT JOIN bug_message bm ON bm.message=m.id + WHERE bm.bug=b.id ORDER BY m.sent_date ASC limit 1) AS message_id, + b.submitter_full AS originator, + EXTRACT(EPOCH FROM b.log_modified) AS log_modified, + EXTRACT(EPOCH FROM b.creation) AS date, + EXTRACT(EPOCH FROM b.last_modified) AS last_modified, + b.done_full AS done, + string_agg(bb.blocks::text,' ' ORDER BY bb.blocks) AS blocks, + string_agg(bbb.bug::text,' ' ORDER BY bbb.bug) AS blockedby, + (SELECT string_agg(bug.bug::text,' ' ORDER BY bug.bug) + FROM (SELECT bm.merged AS bug FROM bug_merged bm WHERE bm.bug=b.id + UNION + SELECT bm.bug AS bug FROM bug_merged bm WHERE bm.merged=b.id) AS bug) AS mergedwith, + (SELECT string_agg(bv.ver_string,' ') FROM bug_ver bv WHERE bv.bug=b.id AND bv.found IS TRUE) + AS found_versions, + (SELECT string_agg(bv.ver_string,' ') FROM bug_ver bv WHERE bv.bug=b.id AND bv.found IS FALSE) + AS fixed_versions + FROM bug b + LEFT JOIN bug_tag bt ON bt.bug=b.id + LEFT JOIN tag t ON bt.tag=t.id + LEFT JOIN bug_blocks bb ON bb.bug=b.id + LEFT JOIN bug_blocks bbb ON bbb.blocks=b.id + GROUP BY b.id;