[Collab-qa-commits] r1523 - udd/sql

Lucas Nussbaum lucas at alioth.debian.org
Fri Jul 17 02:58:15 UTC 2009


Author: lucas
Date: 2009-07-17 02:58:15 +0000 (Fri, 17 Jul 2009)
New Revision: 1523

Modified:
   udd/sql/setup.sql
   udd/sql/upgrade.sql
Log:
release column is now of release type
split all_packages_distrelcomparch
lintian's tag_type is now an enum


Modified: udd/sql/setup.sql
===================================================================
--- udd/sql/setup.sql	2009-07-17 02:55:38 UTC (rev 1522)
+++ udd/sql/setup.sql	2009-07-17 02:58:15 UTC (rev 1523)
@@ -1,11 +1,12 @@
 -- Sources and Packages
+CREATE TYPE release AS ENUM ('hardy', 'intrepid', 'jaunty', 'karmic', 'etch', 'etch-security', 'etch-proposed-updates', 'lenny', 'lenny-security', 'lenny-proposed-updates', 'squeeze', 'squeeze-security', 'squeeze-proposed-updates', 'sid', 'experimental');
 CREATE TABLE sources
   (source text, version debversion, maintainer text,
     maintainer_name text, maintainer_email text, format text, files text,
     uploaders text, bin text, architecture text, standards_version text,
     homepage text, build_depends text, build_depends_indep text,
     build_conflicts text, build_conflicts_indep text, priority text, section
-    text, distribution text, release text, component text, vcs_type text,
+    text, distribution text, release release, component text, vcs_type text,
     vcs_url text, vcs_browser text,
     python_version text, checksums_sha1 text, checksums_sha256 text,
     original_maintainer text, dm_upload_allowed text,
@@ -16,18 +17,22 @@
 -- no primary key possible: duplicate rows are possible because duplicate entries
 -- in Uploaders: are allowed. yes.
 CREATE TABLE uploaders (source text, version debversion, distribution text,
-	release text, component text, name text, email text);
+	release release, component text, name text, email text);
    
 GRANT SELECT ON uploaders TO PUBLIC;
 
+CREATE INDEX uploaders_distrelcompsrcver_idx on uploaders(distribution, release, component, source, version);
+
 CREATE INDEX sources_distrelcomp_idx on sources(distribution, release, component);
 
 CREATE TABLE packages_summary ( package text, version debversion, source text,
-source_version debversion, maintainer text, distribution text, release text,
+source_version debversion, maintainer text, distribution text, release release,
 component text,
 PRIMARY KEY (package, version, distribution, release, component));
 
-CREATE TABLE all_packages_distrelcomparch (distribution text, release text,
+CREATE INDEX packages_summary_distrelcompsrcver_idx on packages_summary(distribution, release, component, source, source_version);
+
+CREATE TABLE packages_distrelcomparch (distribution text, release release,
 component text, architecture text);
 
 CREATE TABLE packages
@@ -38,26 +43,25 @@
     build_essential text, origin text, sha1 text, replaces text, section text,
     md5sum text, bugs text, priority text, tag text, task text, python_version text,
     provides text, conflicts text, sha256 text, original_maintainer text,
-    distribution text, release text, component text,
+    distribution text, release release, component text,
   PRIMARY KEY (package, version, architecture, distribution, release, component),
   FOREIGN KEY (package, version, distribution, release, component) REFERENCES packages_summary DEFERRABLE);
 
 GRANT SELECT ON packages TO PUBLIC;
 GRANT SELECT ON packages_summary TO PUBLIC;
-GRANT SELECT ON all_packages_distrelcomparch TO PUBLIC;
+GRANT SELECT ON packages_distrelcomparch TO PUBLIC;
 
 CREATE INDEX packages_source_idx on packages(source);
 CREATE INDEX packages_distrelcomp_idx on packages(distribution, release, component);
 
 -- Ubuntu sources and packages
-
 CREATE TABLE ubuntu_sources
   (source text, version debversion, maintainer text,
     maintainer_name text, maintainer_email text, format text, files text,
     uploaders text, bin text, architecture text, standards_version text,
     homepage text, build_depends text, build_depends_indep text,
     build_conflicts text, build_conflicts_indep text, priority text, section
-    text, distribution text, release text, component text, vcs_type text,
+    text, distribution text, release release, component text, vcs_type text,
     vcs_url text, vcs_browser text,
     python_version text, checksums_sha1 text, checksums_sha256 text,
     original_maintainer text, dm_upload_allowed text,
@@ -68,15 +72,22 @@
 -- no primary key possible: duplicate rows are possible because duplicate entries
 -- in Uploaders: are allowed. yes.
 CREATE TABLE ubuntu_uploaders (source text, version debversion, distribution text,
-	release text, component text, name text, email text);
+	release release, component text, name text, email text);
    
 GRANT SELECT ON ubuntu_uploaders TO PUBLIC;
 
+CREATE INDEX ubuntu_uploaders_distrelcompsrcver_idx on ubuntu_uploaders(distribution, release, component, source, version);
+
 CREATE TABLE ubuntu_packages_summary ( package text, version debversion, source text,
-source_version debversion, maintainer text, distribution text, release text,
+source_version debversion, maintainer text, distribution text, release release,
 component text,
 PRIMARY KEY (package, version, distribution, release, component));
 
+CREATE INDEX ubuntu_packages_summary_distrelcompsrcver_idx on ubuntu_packages_summary(distribution, release, component, source, source_version);
+
+CREATE TABLE ubuntu_packages_distrelcomparch (distribution text, release release,
+component text, architecture text);
+
 CREATE TABLE ubuntu_packages
   (package text, version debversion, architecture text, maintainer text, description
     text, long_description text, source text, source_version debversion, essential text, depends text,
@@ -85,13 +96,14 @@
     build_essential text, origin text, sha1 text, replaces text, section text,
     md5sum text, bugs text, priority text, tag text, task text, python_version text,
     provides text, conflicts text, sha256 text, original_maintainer text,
-    distribution text, release text, component text,
+    distribution text, release release, component text,
   PRIMARY KEY (package, version, architecture, distribution, release, component),
   FOREIGN KEY (package, version, distribution, release, component) REFERENCES ubuntu_packages_summary DEFERRABLE);
 
 GRANT SELECT ON ubuntu_sources TO PUBLIC;
 GRANT SELECT ON ubuntu_packages TO PUBLIC;
 GRANT SELECT ON ubuntu_packages_summary TO PUBLIC;
+GRANT SELECT ON ubuntu_packages_distrelcomparch TO PUBLIC;
 
 CREATE INDEX ubuntu_packages_source_idx on ubuntu_packages(source);
 CREATE INDEX ubuntu_packages_distrelcomp_idx on ubuntu_packages(distribution, release, component);
@@ -272,21 +284,10 @@
 GRANT SELECT ON ubuntu_popcon_src TO PUBLIC;
 
 -- Lintian
-
-CREATE DOMAIN lintian_tag_type AS TEXT
-NOT NULL
-CHECK(
-     VALUE = 'error'
-  OR VALUE = 'warning'
-  OR VALUE = 'information'
-  OR VALUE = 'experimental'
-  OR VALUE = 'overriden'
-  OR VALUE = 'pedantic'
-);
-
+CREATE TYPE lintian_tagtype AS ENUM('experimental', 'overriden', 'pedantic', 'information', 'warning', 'error');
 CREATE TABLE lintian (
   package TEXT NOT NULL,
-  tag_type lintian_tag_type,
+  tag_type lintian_tagtype NOT NULL,
   package_type TEXT,
   tag TEXT NOT NULL
 );
@@ -417,6 +418,10 @@
 SELECT * FROM packages
 UNION ALL SELECT * FROM ubuntu_packages;
 
+CREATE VIEW all_packages_distrelcomparch AS
+SELECT * FROM packages_distrelcomparch
+UNION ALL SELECT * FROM ubuntu_packages_distrelcomparch;
+
 CREATE VIEW all_bugs AS
 SELECT * FROM bugs
 UNION ALL SELECT * FROM archived_bugs;
@@ -428,7 +433,7 @@
 CREATE TABLE ddtp (
        package      text,
        distribution text,
-       release      text,
+       release      release,
        component    text,   -- == 'main' for the moment
        version      debversion,   -- different versions for a package might exist because some archs
                             -- might have problems with newer versions if a new version comes

Modified: udd/sql/upgrade.sql
===================================================================
--- udd/sql/upgrade.sql	2009-07-17 02:55:38 UTC (rev 1522)
+++ udd/sql/upgrade.sql	2009-07-17 02:58:15 UTC (rev 1523)
@@ -119,3 +119,37 @@
 CREATE INDEX ubuntu_bugs_tasks_idx on ubuntu_bugs_tasks(bug);
 CREATE INDEX ubuntu_bugs_duplicates_idx on ubuntu_bugs_duplicates(bug);
 CREATE INDEX ubuntu_bugs_subscribers_idx on ubuntu_bugs_subscribers(bug);
+
+-- 2009-07-16
+-- turn release columns into ENUMs
+-- you probably want to drop and re-create the tables here, altering
+-- them won't work well
+CREATE TYPE release AS ENUM ('hardy', 'intrepid', 'jaunty', 'karmic', 'etch', 'etch-security', 'etch-proposed-updates', 'lenny', 'lenny-security', 'lenny-proposed-updates', 'squeeze', 'squeeze-security', 'squeeze-proposed-updates', 'sid', 'experimental');
+ALTER TABLE packages ALTER COLUMN release TYPE release USING release::release;
+ALTER TABLE sources ALTER COLUMN release TYPE release USING release::release;
+ALTER TABLE packages_summary ALTER COLUMN release TYPE release USING release::release;
+ALTER TABLE uploaders ALTER COLUMN release TYPE release USING release::release;
+ALTER TABLE ubuntu_packages ALTER COLUMN release TYPE release USING release::release;
+ALTER TABLE ubuntu_sources ALTER COLUMN release TYPE release USING release::release;
+ALTER TABLE ubuntu_packages_summary ALTER COLUMN release TYPE release USING release::release;
+ALTER TABLE ubuntu_uploaders ALTER COLUMN release TYPE release USING release::release;
+ALTER TABLE ddtp ALTER COLUMN release TYPE release USING release::release;
+-- replace all_packages_distrelcomparch with two tables and a view
+DROP TABLE all_packages_distrelcomparch;
+CREATE TABLE packages_distrelcomparch (distribution text, release release,
+component text, architecture text);
+CREATE TABLE ubuntu_packages_distrelcomparch (distribution text, release release,
+component text, architecture text);
+GRANT SELECT ON ubuntu_packages_distrelcomparch TO PUBLIC;
+GRANT SELECT ON packages_distrelcomparch TO PUBLIC;
+CREATE VIEW all_packages_distrelcomparch AS
+SELECT * FROM packages_distrelcomparch
+UNION ALL SELECT * FROM ubuntu_packages_distrelcomparch;
+-- turn lintian tag_type to enum
+CREATE TYPE lintian_tagtype AS ENUM('experimental', 'overriden', 'pedantic', 'information', 'warning', 'error');
+ALTER TABLE lintian ALTER COLUMN tag_type TYPE lintian_tagtype USING tag_type::lintian_tagtype;
+-- add indices needed for enrico's work
+CREATE INDEX uploaders_distrelcompsrcver_idx on uploaders(distribution, release, component, source, version);
+CREATE INDEX ubuntu_uploaders_distrelcompsrcver_idx on ubuntu_uploaders(distribution, release, component, source, version);
+CREATE INDEX packages_summary_distrelcompsrcver_idx on packages_summary(distribution, release, component, source, source_version);
+CREATE INDEX ubuntu_packages_summary_distrelcompsrcver_idx on ubuntu_packages_summary(distribution, release, component, source, source_version);




More information about the Collab-qa-commits mailing list