From cda3163d1f26aa5aca8778d6fe5efb997b9f9235 Mon Sep 17 00:00:00 2001 From: Tomas Kopecek Date: Sep 13 2023 10:17:19 +0000 Subject: PR#3843: Package migration scripts to koji-hub Merges #3843 https://pagure.io/koji/pull-request/3843 Fixes: #3762 https://pagure.io/koji/issue/3762 Move sql schema + migrations to hub package. --- diff --git a/Makefile b/Makefile index 2c52af1..f67a308 100644 --- a/Makefile +++ b/Makefile @@ -9,7 +9,7 @@ PYVER_MAJOR := $(shell $(PYTHON) -c 'import sys; print(".".join(sys.version.spli ifeq ($(PYVER_MAJOR),2) SUBDIRS = builder koji cli plugins vm else - SUBDIRS = kojihub builder koji cli util www plugins vm + SUBDIRS = kojihub builder koji cli util www plugins vm schemas endif diff --git a/docs/README.schema b/docs/README.schema new file mode 100644 index 0000000..a46334f --- /dev/null +++ b/docs/README.schema @@ -0,0 +1 @@ +SQL schema and updates were moved to ../schemas (/usr/share/koji) diff --git a/docs/schema-update-cgen.sql b/docs/schema-update-cgen.sql deleted file mode 100644 index dd7c0f4..0000000 --- a/docs/schema-update-cgen.sql +++ /dev/null @@ -1,112 +0,0 @@ --- PLEASE READ --- This was an interim schema update script for changes introduced after --- 1.10.1. --- You probably want schema-upgrade-1.10-1.11.sql instead of this - - -BEGIN; - --- New tables - -SELECT statement_timestamp(), 'Creating new tables' as msg; - -CREATE TABLE content_generator ( - id SERIAL PRIMARY KEY, - name TEXT -) WITHOUT OIDS; - -CREATE TABLE cg_users ( - cg_id INTEGER NOT NULL REFERENCES content_generator (id), - user_id INTEGER NOT NULL REFERENCES users (id), --- versioned - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, cg_id, user_id), - UNIQUE (cg_id, user_id, active) -) WITHOUT OIDS; - - -CREATE TABLE buildroot_tools_info ( - buildroot_id INTEGER NOT NULL REFERENCES buildroot(id), - tool TEXT NOT NULL, - version TEXT NOT NULL, - PRIMARY KEY (buildroot_id, tool) -) WITHOUT OIDS; - - -CREATE TABLE image_archive_listing ( - image_id INTEGER NOT NULL REFERENCES image_archives(archive_id), - archive_id INTEGER NOT NULL REFERENCES archiveinfo(id), - UNIQUE (image_id, archive_id) -) WITHOUT OIDS; -CREATE INDEX image_listing_archives on image_archive_listing(archive_id); - - --- new columns -- - -select statement_timestamp(), 'Adding new columns' as msg; -ALTER TABLE build ADD COLUMN start_time TIMESTAMP; -ALTER TABLE build ADD COLUMN source TEXT; -ALTER TABLE build ADD COLUMN extra TEXT; -ALTER TABLE rpminfo ADD COLUMN metadata_only BOOLEAN NOT NULL DEFAULT FALSE; -ALTER TABLE rpminfo ADD COLUMN extra TEXT; -ALTER TABLE archiveinfo ADD COLUMN metadata_only BOOLEAN NOT NULL DEFAULT FALSE; -ALTER TABLE archiveinfo ADD COLUMN extra TEXT; - - --- the more complicated stuff - -SELECT statement_timestamp(), 'Copying buildroot to standard_buildroot' as msg; -CREATE TABLE standard_buildroot AS SELECT id,host_id,repo_id,task_id,create_event,retire_event,state from buildroot; --- doing it this way and fixing up after is *much* faster than creating the empty table --- and using insert..select to populate - -SELECT statement_timestamp(), 'Fixing up standard_buildroot table' as msg; -ALTER TABLE standard_buildroot RENAME id TO buildroot_id; -ALTER TABLE standard_buildroot ALTER COLUMN buildroot_id SET NOT NULL; -ALTER TABLE standard_buildroot ALTER COLUMN host_id SET NOT NULL; -ALTER TABLE standard_buildroot ALTER COLUMN repo_id SET NOT NULL; -ALTER TABLE standard_buildroot ALTER COLUMN task_id SET NOT NULL; -ALTER TABLE standard_buildroot ALTER COLUMN create_event SET NOT NULL; -ALTER TABLE standard_buildroot ALTER COLUMN create_event SET DEFAULT get_event(); -SELECT statement_timestamp(), 'Fixing up standard_buildroot table, foreign key constraints' as msg; -ALTER TABLE standard_buildroot ADD CONSTRAINT brfk FOREIGN KEY (buildroot_id) REFERENCES buildroot(id); -ALTER TABLE standard_buildroot ADD CONSTRAINT hfk FOREIGN KEY (host_id) REFERENCES host(id); -ALTER TABLE standard_buildroot ADD CONSTRAINT rfk FOREIGN KEY (repo_id) REFERENCES repo(id); -ALTER TABLE standard_buildroot ADD CONSTRAINT tfk FOREIGN KEY (task_id) REFERENCES task(id); -ALTER TABLE standard_buildroot ADD CONSTRAINT efk FOREIGN KEY (create_event) REFERENCES events(id) ; -SELECT statement_timestamp(), 'Fixing up standard_buildroot table, primary key' as msg; -ALTER TABLE standard_buildroot ADD PRIMARY KEY (buildroot_id); - - -SELECT statement_timestamp(), 'Altering buildroot table (dropping columns)' as msg; -ALTER TABLE buildroot DROP COLUMN host_id; -ALTER TABLE buildroot DROP COLUMN repo_id; -ALTER TABLE buildroot DROP COLUMN task_id; -ALTER TABLE buildroot DROP COLUMN create_event; -ALTER TABLE buildroot DROP COLUMN retire_event; -ALTER TABLE buildroot DROP COLUMN state; -ALTER TABLE buildroot DROP COLUMN dirtyness; - -SELECT statement_timestamp(), 'Altering buildroot table (adding columns)' as msg; -ALTER TABLE buildroot ADD COLUMN br_type INTEGER NOT NULL DEFAULT 0; -ALTER TABLE buildroot ADD COLUMN cg_id INTEGER REFERENCES content_generator (id); -ALTER TABLE buildroot ADD COLUMN cg_version TEXT; -ALTER TABLE buildroot ADD COLUMN container_type TEXT; -ALTER TABLE buildroot ADD COLUMN host_os TEXT; -ALTER TABLE buildroot ADD COLUMN host_arch TEXT; -ALTER TABLE buildroot ADD COLUMN extra TEXT; - -SELECT statement_timestamp(), 'Altering buildroot table (altering columns)' as msg; -ALTER TABLE buildroot RENAME arch TO container_arch; -ALTER TABLE buildroot ALTER COLUMN container_arch TYPE TEXT; -ALTER TABLE buildroot ALTER COLUMN br_type DROP DEFAULT; - -COMMIT; - diff --git a/docs/schema-update-cgen2.sql b/docs/schema-update-cgen2.sql deleted file mode 100644 index 2748567..0000000 --- a/docs/schema-update-cgen2.sql +++ /dev/null @@ -1,91 +0,0 @@ --- PLEASE READ --- This was an interim schema update script for changes introduced after --- 1.10.1. --- You probably want schema-upgrade-1.10-1.11.sql instead of this - - -BEGIN; - --- New tables - -SELECT statement_timestamp(), 'Creating new tables' as msg; - -CREATE TABLE btype ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -) WITHOUT OIDS; - -CREATE TABLE build_types ( - build_id INTEGER NOT NULL REFERENCES build(id), - btype_id INTEGER NOT NULL REFERENCES btype(id), - PRIMARY KEY (build_id, btype_id) -) WITHOUT OIDS; - --- predefined build types - -SELECT statement_timestamp(), 'Adding predefined build types' as msg; -INSERT INTO btype(name) VALUES ('rpm'); -INSERT INTO btype(name) VALUES ('maven'); -INSERT INTO btype(name) VALUES ('win'); -INSERT INTO btype(name) VALUES ('image'); - --- new column for archiveinfo - -SELECT statement_timestamp(), 'Altering archiveinfo table' as msg; -ALTER TABLE archiveinfo ADD COLUMN btype_id INTEGER REFERENCES btype(id); - --- fill in legacy types -SELECT statement_timestamp(), 'Adding legacy btypes to builds' as msg; -INSERT INTO build_types(btype_id, build_id) - SELECT btype.id, maven_builds.build_id FROM btype JOIN maven_builds ON btype.name='maven'; -INSERT INTO build_types(btype_id, build_id) - SELECT btype.id, win_builds.build_id FROM btype JOIN win_builds ON btype.name='win'; -INSERT INTO build_types(btype_id, build_id) - SELECT btype.id, image_builds.build_id FROM btype JOIN image_builds ON btype.name='image'; --- not sure if this is the best way to select rpm builds... -INSERT INTO build_types(btype_id, build_id) - SELECT DISTINCT btype.id, build_id FROM btype JOIN rpminfo ON btype.name='rpm' - WHERE build_id IS NOT NULL; - -SELECT statement_timestamp(), 'Adding legacy btypes to archiveinfo' as msg; -UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='maven' LIMIT 1) - WHERE (SELECT archive_id FROM maven_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; -UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='win' LIMIT 1) - WHERE (SELECT archive_id FROM win_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; -UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='image' LIMIT 1) - WHERE (SELECT archive_id FROM image_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; - --- new component tables -SELECT statement_timestamp(), 'Creating new component tables' as msg; -CREATE TABLE archive_rpm_components AS SELECT image_id, rpm_id from image_listing; -CREATE TABLE archive_components AS SELECT image_id, archive_id from image_archive_listing; --- doing it this way and fixing up after is *much* faster than creating the empty table --- and using insert..select to populate - -SELECT statement_timestamp(), 'Fixing up component tables, rename columns' as msg; -ALTER TABLE archive_rpm_components RENAME image_id TO archive_id; -ALTER TABLE archive_components RENAME archive_id TO component_id; -ALTER TABLE archive_components RENAME image_id TO archive_id; -ALTER TABLE archive_rpm_components ALTER COLUMN rpm_id SET NOT NULL; -ALTER TABLE archive_rpm_components ALTER COLUMN archive_id SET NOT NULL; -ALTER TABLE archive_components ALTER COLUMN component_id SET NOT NULL; -ALTER TABLE archive_components ALTER COLUMN archive_id SET NOT NULL; - -SELECT statement_timestamp(), 'Fixing up component tables, adding constraints' as msg; -ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_archive_id_fkey FOREIGN KEY (archive_id) REFERENCES archiveinfo(id); -ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_rpm_id_fkey FOREIGN KEY (rpm_id) REFERENCES rpminfo(id); -ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_archive_id_rpm_id_key UNIQUE (archive_id, rpm_id); -ALTER TABLE archive_components ADD CONSTRAINT archive_components_archive_id_fkey FOREIGN KEY (archive_id) REFERENCES archiveinfo(id); -ALTER TABLE archive_components ADD CONSTRAINT archive_components_component_id_fkey FOREIGN KEY (component_id) REFERENCES archiveinfo(id); -ALTER TABLE archive_components ADD CONSTRAINT archive_components_archive_id_component_id_key UNIQUE (archive_id, component_id); - -SELECT statement_timestamp(), 'Adding component table indexes' as msg; -CREATE INDEX rpm_components_idx on archive_rpm_components(rpm_id); -CREATE INDEX archive_components_idx on archive_components(component_id); - - --- image_listing and image_archive_listing are no longer used - - -COMMIT; - diff --git a/docs/schema-update-dist-repos.sql b/docs/schema-update-dist-repos.sql deleted file mode 100644 index ef71423..0000000 --- a/docs/schema-update-dist-repos.sql +++ /dev/null @@ -1,7 +0,0 @@ -# schema updates for dist repo feature -# to be merged into schema upgrade script for next release - -INSERT INTO permissions (name) VALUES ('image'); - -ALTER TABLE repo ADD COLUMN dist BOOLEAN DEFAULT 'false'; - diff --git a/docs/schema-upgrade-1.10-1.11.sql b/docs/schema-upgrade-1.10-1.11.sql deleted file mode 100644 index 4ae2bf5..0000000 --- a/docs/schema-upgrade-1.10-1.11.sql +++ /dev/null @@ -1,206 +0,0 @@ - -BEGIN; - --- from schema-update-cgen.sql - - --- New tables - -SELECT statement_timestamp(), 'Creating new tables' as msg; - -CREATE TABLE content_generator ( - id SERIAL PRIMARY KEY, - name TEXT -) WITHOUT OIDS; - -CREATE TABLE cg_users ( - cg_id INTEGER NOT NULL REFERENCES content_generator (id), - user_id INTEGER NOT NULL REFERENCES users (id), --- versioned - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, cg_id, user_id), - UNIQUE (cg_id, user_id, active) -) WITHOUT OIDS; - - -CREATE TABLE buildroot_tools_info ( - buildroot_id INTEGER NOT NULL REFERENCES buildroot(id), - tool TEXT NOT NULL, - version TEXT NOT NULL, - PRIMARY KEY (buildroot_id, tool) -) WITHOUT OIDS; - - -CREATE TABLE image_archive_listing ( - image_id INTEGER NOT NULL REFERENCES image_archives(archive_id), - archive_id INTEGER NOT NULL REFERENCES archiveinfo(id), - UNIQUE (image_id, archive_id) -) WITHOUT OIDS; -CREATE INDEX image_listing_archives on image_archive_listing(archive_id); - - --- new columns -- - -select statement_timestamp(), 'Adding new columns' as msg; -ALTER TABLE build ADD COLUMN start_time TIMESTAMP; -ALTER TABLE build ADD COLUMN source TEXT; -ALTER TABLE build ADD COLUMN extra TEXT; -ALTER TABLE rpminfo ADD COLUMN metadata_only BOOLEAN NOT NULL DEFAULT FALSE; -ALTER TABLE rpminfo ADD COLUMN extra TEXT; -ALTER TABLE archiveinfo ADD COLUMN metadata_only BOOLEAN NOT NULL DEFAULT FALSE; -ALTER TABLE archiveinfo ADD COLUMN extra TEXT; - - --- the more complicated stuff - -SELECT statement_timestamp(), 'Copying buildroot to standard_buildroot' as msg; -CREATE TABLE standard_buildroot AS SELECT id,host_id,repo_id,task_id,create_event,retire_event,state from buildroot; --- doing it this way and fixing up after is *much* faster than creating the empty table --- and using insert..select to populate - -SELECT statement_timestamp(), 'Fixing up standard_buildroot table' as msg; -ALTER TABLE standard_buildroot RENAME id TO buildroot_id; -ALTER TABLE standard_buildroot ALTER COLUMN buildroot_id SET NOT NULL; -ALTER TABLE standard_buildroot ALTER COLUMN host_id SET NOT NULL; -ALTER TABLE standard_buildroot ALTER COLUMN repo_id SET NOT NULL; -ALTER TABLE standard_buildroot ALTER COLUMN task_id SET NOT NULL; -ALTER TABLE standard_buildroot ALTER COLUMN create_event SET NOT NULL; -ALTER TABLE standard_buildroot ALTER COLUMN create_event SET DEFAULT get_event(); -SELECT statement_timestamp(), 'Fixing up standard_buildroot table, foreign key constraints' as msg; -ALTER TABLE standard_buildroot ADD CONSTRAINT standard_buildroot_buildroot_id_fkey FOREIGN KEY (buildroot_id) REFERENCES buildroot(id); -ALTER TABLE standard_buildroot ADD CONSTRAINT standard_buildroot_host_id_fkey FOREIGN KEY (host_id) REFERENCES host(id); -ALTER TABLE standard_buildroot ADD CONSTRAINT standard_buildroot_repo_id_fkey FOREIGN KEY (repo_id) REFERENCES repo(id); -ALTER TABLE standard_buildroot ADD CONSTRAINT standard_buildroot_task_id_fkey FOREIGN KEY (task_id) REFERENCES task(id); -ALTER TABLE standard_buildroot ADD CONSTRAINT standard_buildroot_create_event_fkey FOREIGN KEY (create_event) REFERENCES events(id) ; -SELECT statement_timestamp(), 'Fixing up standard_buildroot table, primary key' as msg; -ALTER TABLE standard_buildroot ADD PRIMARY KEY (buildroot_id); - - -SELECT statement_timestamp(), 'Altering buildroot table (dropping columns)' as msg; -ALTER TABLE buildroot DROP COLUMN host_id; -ALTER TABLE buildroot DROP COLUMN repo_id; -ALTER TABLE buildroot DROP COLUMN task_id; -ALTER TABLE buildroot DROP COLUMN create_event; -ALTER TABLE buildroot DROP COLUMN retire_event; -ALTER TABLE buildroot DROP COLUMN state; -ALTER TABLE buildroot DROP COLUMN dirtyness; - -SELECT statement_timestamp(), 'Altering buildroot table (adding columns)' as msg; -ALTER TABLE buildroot ADD COLUMN br_type INTEGER NOT NULL DEFAULT 0; -ALTER TABLE buildroot ADD COLUMN cg_id INTEGER REFERENCES content_generator (id); -ALTER TABLE buildroot ADD COLUMN cg_version TEXT; -ALTER TABLE buildroot ADD COLUMN container_type TEXT; -ALTER TABLE buildroot ADD COLUMN host_os TEXT; -ALTER TABLE buildroot ADD COLUMN host_arch TEXT; -ALTER TABLE buildroot ADD COLUMN extra TEXT; - -SELECT statement_timestamp(), 'Altering buildroot table (altering columns)' as msg; -ALTER TABLE buildroot RENAME arch TO container_arch; -ALTER TABLE buildroot ALTER COLUMN container_arch TYPE TEXT; -ALTER TABLE buildroot ALTER COLUMN br_type DROP DEFAULT; - -SELECT statement_timestamp(), 'Altering buildroot table (altering constraints)' as msg; -ALTER TABLE buildroot ADD CONSTRAINT cg_sane CHECK ( - (cg_id IS NULL AND cg_version IS NULL) - OR (cg_id IS NOT NULL AND cg_version IS NOT NULL)); -UPDATE buildroot SET container_type = 'chroot' WHERE container_type IS NULL AND container_arch IS NOT NULL; -ALTER TABLE buildroot ADD CONSTRAINT container_sane CHECK ( - (container_type IS NULL AND container_arch IS NULL) - OR (container_type IS NOT NULL AND container_arch IS NOT NULL)); -ALTER TABLE buildroot ALTER COLUMN container_arch DROP NOT NULL; - - - --- from schema-update-cgen2.sql - - --- New tables - -SELECT statement_timestamp(), 'Creating new tables' as msg; - -CREATE TABLE btype ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -) WITHOUT OIDS; - -CREATE TABLE build_types ( - build_id INTEGER NOT NULL REFERENCES build(id), - btype_id INTEGER NOT NULL REFERENCES btype(id), - PRIMARY KEY (build_id, btype_id) -) WITHOUT OIDS; - --- predefined build types - -SELECT statement_timestamp(), 'Adding predefined build types' as msg; -INSERT INTO btype(name) VALUES ('rpm'); -INSERT INTO btype(name) VALUES ('maven'); -INSERT INTO btype(name) VALUES ('win'); -INSERT INTO btype(name) VALUES ('image'); - --- new column for archiveinfo - -SELECT statement_timestamp(), 'Altering archiveinfo table' as msg; -ALTER TABLE archiveinfo ADD COLUMN btype_id INTEGER REFERENCES btype(id); - --- fill in legacy types -SELECT statement_timestamp(), 'Adding legacy btypes to builds' as msg; -INSERT INTO build_types(btype_id, build_id) - SELECT btype.id, maven_builds.build_id FROM btype JOIN maven_builds ON btype.name='maven'; -INSERT INTO build_types(btype_id, build_id) - SELECT btype.id, win_builds.build_id FROM btype JOIN win_builds ON btype.name='win'; -INSERT INTO build_types(btype_id, build_id) - SELECT btype.id, image_builds.build_id FROM btype JOIN image_builds ON btype.name='image'; --- not sure if this is the best way to select rpm builds... -INSERT INTO build_types(btype_id, build_id) - SELECT DISTINCT btype.id, build_id FROM btype JOIN rpminfo ON btype.name='rpm' - WHERE build_id IS NOT NULL; - -SELECT statement_timestamp(), 'Adding legacy btypes to archiveinfo' as msg; -UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='maven' LIMIT 1) - WHERE (SELECT archive_id FROM maven_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; -UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='win' LIMIT 1) - WHERE (SELECT archive_id FROM win_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; -UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='image' LIMIT 1) - WHERE (SELECT archive_id FROM image_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; - --- new component tables -SELECT statement_timestamp(), 'Creating new component tables' as msg; -CREATE TABLE archive_rpm_components AS SELECT image_id, rpm_id from image_listing; -CREATE TABLE archive_components AS SELECT image_id, archive_id from image_archive_listing; --- doing it this way and fixing up after is *much* faster than creating the empty table --- and using insert..select to populate - -SELECT statement_timestamp(), 'Fixing up component tables, rename columns' as msg; -ALTER TABLE archive_rpm_components RENAME image_id TO archive_id; -ALTER TABLE archive_components RENAME archive_id TO component_id; -ALTER TABLE archive_components RENAME image_id TO archive_id; -ALTER TABLE archive_rpm_components ALTER COLUMN rpm_id SET NOT NULL; -ALTER TABLE archive_rpm_components ALTER COLUMN archive_id SET NOT NULL; -ALTER TABLE archive_components ALTER COLUMN component_id SET NOT NULL; -ALTER TABLE archive_components ALTER COLUMN archive_id SET NOT NULL; - -SELECT statement_timestamp(), 'Fixing up component tables, adding constraints' as msg; -ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_archive_id_fkey FOREIGN KEY (archive_id) REFERENCES archiveinfo(id); -ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_rpm_id_fkey FOREIGN KEY (rpm_id) REFERENCES rpminfo(id); -ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_archive_id_rpm_id_key UNIQUE (archive_id, rpm_id); -ALTER TABLE archive_components ADD CONSTRAINT archive_components_archive_id_fkey FOREIGN KEY (archive_id) REFERENCES archiveinfo(id); -ALTER TABLE archive_components ADD CONSTRAINT archive_components_component_id_fkey FOREIGN KEY (component_id) REFERENCES archiveinfo(id); -ALTER TABLE archive_components ADD CONSTRAINT archive_components_archive_id_component_id_key UNIQUE (archive_id, component_id); - -SELECT statement_timestamp(), 'Adding component table indexes' as msg; -CREATE INDEX rpm_components_idx on archive_rpm_components(rpm_id); -CREATE INDEX archive_components_idx on archive_components(component_id); - - --- image_listing and image_archive_listing are no longer used - - -COMMIT; - diff --git a/docs/schema-upgrade-1.11-1.12.sql b/docs/schema-upgrade-1.11-1.12.sql deleted file mode 100644 index 8659de7..0000000 --- a/docs/schema-upgrade-1.11-1.12.sql +++ /dev/null @@ -1,11 +0,0 @@ -BEGIN; - --- from schema-update-dist-repos.sql - -INSERT INTO permissions (name) VALUES ('image'); - -ALTER TABLE repo ADD COLUMN dist BOOLEAN; -ALTER TABLE repo ALTER COLUMN dist SET DEFAULT 'false'; -UPDATE repo SET dist = 'false'; - -COMMIT; diff --git a/docs/schema-upgrade-1.12-1.13.sql b/docs/schema-upgrade-1.12-1.13.sql deleted file mode 100644 index 5a87ec3..0000000 --- a/docs/schema-upgrade-1.12-1.13.sql +++ /dev/null @@ -1,9 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.12 to 1.13 - -BEGIN; - --- Change VARCHAR field for tag names to TEXT to allow longer tag names -ALTER TABLE tag ALTER COLUMN name TYPE TEXT; - -COMMIT; diff --git a/docs/schema-upgrade-1.13-1.14.sql b/docs/schema-upgrade-1.13-1.14.sql deleted file mode 100644 index 16b4227..0000000 --- a/docs/schema-upgrade-1.13-1.14.sql +++ /dev/null @@ -1,13 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.13 to 1.14 - -BEGIN; - --- drop unused log_messages table -DROP TABLE log_messages; - --- add yaml and xjb file type in archivetypes -insert into archivetypes (name, description, extensions) values ('yaml', 'YAML Ain''t Markup Language', 'yaml yml'); -insert into archivetypes (name, description, extensions) values ('xjb', 'JAXB(Java Architecture for XML Binding) Binding Customization File', 'xjb'); - -COMMIT; diff --git a/docs/schema-upgrade-1.14-1.15.sql b/docs/schema-upgrade-1.14-1.15.sql deleted file mode 100644 index dd4e026..0000000 --- a/docs/schema-upgrade-1.14-1.15.sql +++ /dev/null @@ -1,3 +0,0 @@ --- Nothing to do --- --- There were no schema changes between 1.14 and 1.15 diff --git a/docs/schema-upgrade-1.15-1.16.sql b/docs/schema-upgrade-1.15-1.16.sql deleted file mode 100644 index 97586ba..0000000 --- a/docs/schema-upgrade-1.15-1.16.sql +++ /dev/null @@ -1,66 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.14 to 1.16 - - -BEGIN; - --- create host_config table -SELECT 'Creating table host_config'; -CREATE TABLE host_config ( - host_id INTEGER NOT NULL REFERENCES host(id), - arches TEXT, - capacity FLOAT CHECK (capacity > 1) NOT NULL DEFAULT 2.0, - description TEXT, - comment TEXT, - enabled BOOLEAN NOT NULL DEFAULT 'true', --- versioned - see desc above - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, host_id), - UNIQUE (host_id, active) -) WITHOUT OIDS; -CREATE INDEX host_config_by_active_and_enabled ON host_config(active, enabled); - --- copy starting data --- CREATE FUNCTION pg_temp.user() returns INTEGER as $$ select id from users where name='nobody' $$ language SQL; -CREATE FUNCTION pg_temp.user() returns INTEGER as $$ select 1 $$ language SQL; --- If you would like to use an existing user instead, then: --- 1. edit the temporary function to look for the alternate user name - -SELECT 'Copying data from host to host_config'; -INSERT INTO host_config (host_id, arches, capacity, description, comment, enabled, creator_id) - SELECT id, arches, capacity, description, comment, enabled, pg_temp.user() FROM host; - --- alter original table -SELECT 'Dropping moved columns'; -ALTER TABLE host DROP COLUMN arches; -ALTER TABLE host DROP COLUMN capacity; -ALTER TABLE host DROP COLUMN description; -ALTER TABLE host DROP COLUMN comment; -ALTER TABLE host DROP COLUMN enabled; - --- history for host_channels -SELECT 'Adding versions to host_channels'; -ALTER TABLE host_channels ADD COLUMN create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(); -ALTER TABLE host_channels ADD COLUMN revoke_event INTEGER REFERENCES events(id); --- we need some default for alter table, but drop it after -ALTER TABLE host_channels ADD COLUMN creator_id INTEGER NOT NULL REFERENCES users(id) DEFAULT pg_temp.user(); -ALTER TABLE host_channels ALTER COLUMN creator_id DROP DEFAULT; -ALTER TABLE host_channels ADD COLUMN revoker_id INTEGER REFERENCES users(id); -ALTER TABLE host_channels ADD COLUMN active BOOLEAN DEFAULT 'true' CHECK (active); -ALTER TABLE host_channels ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); -ALTER TABLE host_channels ADD PRIMARY KEY (create_event, host_id, channel_id); -ALTER TABLE host_channels ADD UNIQUE (host_id, channel_id, active); -ALTER TABLE host_channels DROP CONSTRAINT host_channels_host_id_channel_id_key; --- drop potential very old constraint (https://pagure.io/koji/issue/1789) -ALTER TABLE host_channels DROP CONSTRAINT IF EXISTS host_channels_host_id_key; - -COMMIT; diff --git a/docs/schema-upgrade-1.16-1.17.sql b/docs/schema-upgrade-1.16-1.17.sql deleted file mode 100644 index 6cb9ad6..0000000 --- a/docs/schema-upgrade-1.16-1.17.sql +++ /dev/null @@ -1,13 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.16 to 1.17 - - -BEGIN; - --- Change VARCHAR field for build_target names to TEXT to allow longer names -ALTER TABLE build_target ALTER COLUMN name TYPE TEXT; - --- Allow different merge modes for mergerepo -ALTER TABLE tag_external_repos ADD COLUMN merge_mode TEXT DEFAULT 'koji'; - -COMMIT; diff --git a/docs/schema-upgrade-1.17-1.18.sql b/docs/schema-upgrade-1.17-1.18.sql deleted file mode 100644 index 751d7d7..0000000 --- a/docs/schema-upgrade-1.17-1.18.sql +++ /dev/null @@ -1,45 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.17 to 1.18 - - -BEGIN; - --- new table for notifications' optouts -CREATE TABLE build_notifications_block ( - id SERIAL NOT NULL PRIMARY KEY, - user_id INTEGER NOT NULL REFERENCES users (id), - package_id INTEGER REFERENCES package (id), - tag_id INTEGER REFERENCES tag (id) -) WITHOUT OIDS; - --- add tgz to list of tar's extensions -UPDATE archivetypes SET extensions = 'tar tar.gz tar.bz2 tar.xz tgz' WHERE name = 'tar'; -INSERT INTO archivetypes (name, description, extensions) VALUES ('vhdx', 'Hyper-V Virtual Hard Disk v2 image', 'vhdx'); - --- add compressed raw-gzip and compressed qcow2 images -insert into archivetypes (name, description, extensions) values ('raw-gz', 'GZIP compressed raw disk image', 'raw.gz'); -insert into archivetypes (name, description, extensions) values ('qcow2-compressed', 'Compressed QCOW2 image', 'qcow2.gz qcow2.xz'); - --- add better index for sessions -CREATE INDEX sessions_expired ON sessions(expired); - --- table for content generator build reservations -CREATE TABLE build_reservations ( - build_id INTEGER NOT NULL REFERENCES build(id), - token VARCHAR(64), - created TIMESTAMP NOT NULL, - PRIMARY KEY (build_id) -) WITHOUT OIDS; -CREATE INDEX build_reservations_created ON build_reservations(created); - -ALTER TABLE build ADD COLUMN cg_id INTEGER REFERENCES content_generator(id); - - --- new indexes added in 1.18 -CREATE INDEX tag_packages_active_tag_id ON tag_packages(active, tag_id); -CREATE INDEX tag_packages_create_event ON tag_packages(create_event); -CREATE INDEX tag_packages_revoke_event ON tag_packages(revoke_event); -CREATE INDEX tag_packages_owner ON tag_packages(owner); - - -COMMIT; diff --git a/docs/schema-upgrade-1.18-1.19.sql b/docs/schema-upgrade-1.18-1.19.sql deleted file mode 100644 index e071f2a..0000000 --- a/docs/schema-upgrade-1.18-1.19.sql +++ /dev/null @@ -1,93 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.18 to 1.19 - - -BEGIN; - -CREATE TABLE tag_package_owners ( - package_id INTEGER NOT NULL REFERENCES package(id), - tag_id INTEGER NOT NULL REFERENCES tag (id), - owner INTEGER NOT NULL REFERENCES users(id), --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, package_id, tag_id), - UNIQUE (package_id,tag_id,active) -) WITHOUT OIDS; - -CREATE OR REPLACE FUNCTION convert_owners() RETURNS SETOF tag_packages AS -$BODY$ -DECLARE - r tag_packages%rowtype; - r2 tag_packages%rowtype; - last_owner int; -BEGIN - FOR r IN SELECT package_id, tag_id FROM tag_packages GROUP BY package_id, tag_id ORDER BY package_id, tag_id - LOOP - last_owner := 0; - FOR r2 IN SELECT * FROM tag_packages WHERE package_id = r.package_id AND tag_id = r.tag_id ORDER BY create_event - LOOP - -- always use first and last (active) row - IF last_owner = 0 OR r2.active IS TRUE THEN - last_owner := r2.owner; - RETURN NEXT r2; -- return current row of SELECT - ELSE - -- copy others only if owner changed - IF last_owner <> r2.owner THEN - RETURN NEXT r2; - last_owner := r2.owner; - END IF; - END IF; - END LOOP; - END LOOP; - RETURN; -END -$BODY$ -LANGUAGE plpgsql; - -INSERT INTO tag_package_owners (SELECT package_id, tag_id, owner, create_event, revoke_event, creator_id, revoker_id, active FROM convert_owners()); -DROP INDEX IF EXISTS tag_packages_owner; -ALTER TABLE tag_packages DROP COLUMN owner; -DROP FUNCTION convert_owners(); - --- add compressed iso-compressed, vhd-compressed, vhdx-compressed, and vmdk-compressed -insert into archivetypes (name, description, extensions) values ('iso-compressed', 'Compressed iso image', 'iso.gz iso.xz'); -insert into archivetypes (name, description, extensions) values ('vhd-compressed', 'Compressed VHD image', 'vhd.gz vhd.xz'); -insert into archivetypes (name, description, extensions) values ('vhdx-compressed', 'Compressed VHDx image', 'vhd.gz vhd.xz'); -insert into archivetypes (name, description, extensions) values ('vmdk-compressed', 'Compressed VMDK image', 'vmdk.gz vmdk.xz'); - --- add kernel-image and imitramfs -insert into archivetypes (name, description, extensions) values ('kernel-image', 'Kernel BZ2 Image', 'vmlinuz vmlinuz.gz vmlinuz.xz'); -insert into archivetypes (name, description, extensions) values ('initramfs', 'Compressed Initramfs Image', 'img'); - --- schema update for https://pagure.io/koji/issue/1629 -CREATE TABLE user_krb_principals ( - user_id INTEGER NOT NULL REFERENCES users(id), - krb_principal VARCHAR(255) NOT NULL UNIQUE, - PRIMARY KEY (user_id, krb_principal) -) WITHOUT OIDS; - -INSERT INTO user_krb_principals ( SELECT id, krb_principal FROM users WHERE users.krb_principal IS NOT NULL); - -ALTER TABLE users DROP COLUMN krb_principal; - --- Disallow duplicate content generator names -ALTER TABLE content_generator ADD UNIQUE (name); -ALTER TABLE content_generator ALTER COLUMN name SET NOT NULL; - - --- add all basic permissions -INSERT INTO permissions (name) SELECT 'dist-repo' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'dist-repo'); -INSERT INTO permissions (name) SELECT 'host' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'host'); -INSERT INTO permissions (name) SELECT 'image-import' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'image-import'); -INSERT INTO permissions (name) SELECT 'sign' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'sign'); -INSERT INTO permissions (name) SELECT 'tag' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'tag'); -INSERT INTO permissions (name) SELECT 'target' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'target'); - -COMMIT; diff --git a/docs/schema-upgrade-1.19-1.20.sql b/docs/schema-upgrade-1.19-1.20.sql deleted file mode 100644 index 66dcebe..0000000 --- a/docs/schema-upgrade-1.19-1.20.sql +++ /dev/null @@ -1,10 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.19 to 1.20 - - -BEGIN; - --- drop potential very old constraint (https://pagure.io/koji/issue/1789) -ALTER TABLE host_channels DROP CONSTRAINT IF EXISTS host_channels_host_id_key; - -COMMIT; diff --git a/docs/schema-upgrade-1.2-1.3.sql b/docs/schema-upgrade-1.2-1.3.sql deleted file mode 100644 index c970115..0000000 --- a/docs/schema-upgrade-1.2-1.3.sql +++ /dev/null @@ -1,62 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.2 to 1.3 - -BEGIN; - --- external yum repos -create table external_repo ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -); --- fake repo id for internal stuff (needed for unique index) -INSERT INTO external_repo (id, name) VALUES (0, 'INTERNAL'); - -create table external_repo_config ( - external_repo_id INTEGER NOT NULL REFERENCES external_repo(id), - url TEXT NOT NULL, --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL ) - OR (active IS NOT NULL AND revoke_event IS NULL )), - PRIMARY KEY (create_event, external_repo_id), - UNIQUE (external_repo_id, active) -) WITHOUT OIDS; - -create table tag_external_repos ( - tag_id INTEGER NOT NULL REFERENCES tag(id), - external_repo_id INTEGER NOT NULL REFERENCES external_repo(id), - priority INTEGER NOT NULL, --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL ) - OR (active IS NOT NULL AND revoke_event IS NULL )), - PRIMARY KEY (create_event, tag_id, priority), - UNIQUE (tag_id, priority, active), - UNIQUE (tag_id, external_repo_id, active) -); - --- add the new column then set the existing packages to have the INTERNAL exteranl repo id --- then add the not null constraint --- then drop rpminfo_unique_nvra CONSTRAINT and add the new version -ALTER TABLE rpminfo ADD COLUMN external_repo_id INTEGER REFERENCES external_repo(id); -UPDATE rpminfo SET external_repo_id = 0; -ALTER TABLE rpminfo ALTER COLUMN external_repo_id SET NOT NULL; -ALTER TABLE rpminfo DROP CONSTRAINT rpminfo_unique_nvra; -ALTER TABLE rpminfo ADD CONSTRAINT rpminfo_unique_nvra UNIQUE (name,version,release,arch,external_repo_id); - -GRANT SELECT ON external_repo, external_repo_config, tag_external_repos TO PUBLIC; - --- these tables are no longer included with newer koji --- feel free to drop them --- DROP TABLE rpmfiles; --- DROP TABLE rpmdeps; --- DROP TABLE changelogs; --- DROP TABLE archivefiles; - -COMMIT; diff --git a/docs/schema-upgrade-1.20-1.21.sql b/docs/schema-upgrade-1.20-1.21.sql deleted file mode 100644 index 0cce0dd..0000000 --- a/docs/schema-upgrade-1.20-1.21.sql +++ /dev/null @@ -1,20 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.20 to 1.21 - - -BEGIN; - --- make better events -ALTER TABLE events ALTER COLUMN time SET NOT NULL; -ALTER TABLE events ALTER COLUMN time SET DEFAULT clock_timestamp(); - -CREATE OR REPLACE FUNCTION get_event() RETURNS INTEGER AS ' - INSERT INTO events (time) VALUES (clock_timestamp()); - SELECT currval(''events_id_seq'')::INTEGER; -' LANGUAGE SQL; - --- merge_mode can not be null -UPDATE tag_external_repos SET merge_mode = 'koji' WHERE merge_mode is NULL; -ALTER TABLE tag_external_repos ALTER COLUMN merge_mode SET NOT NULL; - -COMMIT; diff --git a/docs/schema-upgrade-1.21-1.22.sql b/docs/schema-upgrade-1.21-1.22.sql deleted file mode 100644 index b07b87e..0000000 --- a/docs/schema-upgrade-1.21-1.22.sql +++ /dev/null @@ -1,35 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.20 to 1.21 - - -BEGIN; - -ALTER TABLE events ALTER COLUMN time TYPE TIMESTAMPTZ USING - timezone(current_setting('TIMEZONE'), time::timestamptz); -ALTER TABLE sessions ALTER COLUMN start_time TYPE TIMESTAMPTZ USING - timezone(current_setting('TIMEZONE'), start_time::timestamptz); -ALTER TABLE sessions ALTER COLUMN update_time TYPE TIMESTAMPTZ USING - timezone(current_setting('TIMEZONE'), update_time::timestamptz); -ALTER TABLE task ALTER COLUMN create_time TYPE TIMESTAMPTZ USING - timezone(current_setting('TIMEZONE'), create_time::timestamptz); -ALTER TABLE task ALTER COLUMN start_time TYPE TIMESTAMPTZ USING - timezone(current_setting('TIMEZONE'), start_time::timestamptz); -ALTER TABLE task ALTER COLUMN completion_time TYPE TIMESTAMPTZ USING - timezone(current_setting('TIMEZONE'), completion_time::timestamptz); -ALTER TABLE build ALTER COLUMN start_time TYPE TIMESTAMPTZ USING - timezone(current_setting('TIMEZONE'), start_time::timestamptz); -ALTER TABLE build ALTER COLUMN completion_time TYPE TIMESTAMPTZ USING - timezone(current_setting('TIMEZONE'), completion_time::timestamptz); -ALTER TABLE build_reservations ALTER COLUMN created TYPE TIMESTAMPTZ USING - timezone(current_setting('TIMEZONE'), created::timestamptz); - --- input type has to be specified on PostgreSQL 9.x -DROP FUNCTION IF EXISTS get_event_time(INTEGER); -CREATE FUNCTION get_event_time(INTEGER) RETURNS TIMESTAMPTZ AS ' - SELECT time FROM events WHERE id=$1; -' LANGUAGE SQL; - -DROP INDEX IF EXISTS sessions_active_and_recent; -CREATE INDEX sessions_active_and_recent ON sessions(expired, master, update_time) WHERE (expired = FALSE AND master IS NULL); - -COMMIT; diff --git a/docs/schema-upgrade-1.22-1.23.sql b/docs/schema-upgrade-1.22-1.23.sql deleted file mode 100644 index b79ac29..0000000 --- a/docs/schema-upgrade-1.22-1.23.sql +++ /dev/null @@ -1,21 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.22 to 1.23 - - -BEGIN; - -CREATE INDEX task_by_no_parent_state_method ON task(parent, state, method) WHERE parent IS NULL; - -ALTER TABLE tag_extra ALTER COLUMN value DROP NOT NULL; - --- Message queue for the protonmsg plugin -CREATE TABLE proton_queue ( - id SERIAL PRIMARY KEY, - created_ts TIMESTAMPTZ DEFAULT NOW(), - address TEXT NOT NULL, - props JSON NOT NULL, - body JSON NOT NULL -) WITHOUT OIDS; - - -COMMIT; diff --git a/docs/schema-upgrade-1.23-1.24.sql b/docs/schema-upgrade-1.23-1.24.sql deleted file mode 100644 index 998849a..0000000 --- a/docs/schema-upgrade-1.23-1.24.sql +++ /dev/null @@ -1,9 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.23 to 1.24 - - -BEGIN; - -ALTER TABLE tag_external_repos ADD COLUMN arches TEXT; - -COMMIT; diff --git a/docs/schema-upgrade-1.24-1.25.sql b/docs/schema-upgrade-1.24-1.25.sql deleted file mode 100644 index 0ddf6f2..0000000 --- a/docs/schema-upgrade-1.24-1.25.sql +++ /dev/null @@ -1,9 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.24 to 1.25 - - -BEGIN; - -ALTER TABLE repo ADD COLUMN task_id INTEGER NULL REFERENCES task(id); - -COMMIT; diff --git a/docs/schema-upgrade-1.25-1.26.sql b/docs/schema-upgrade-1.25-1.26.sql deleted file mode 100644 index 18cdf5f..0000000 --- a/docs/schema-upgrade-1.25-1.26.sql +++ /dev/null @@ -1,11 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.25 to 1.26 - - -BEGIN; - -ALTER TABLE channels ADD COLUMN description TEXT; -ALTER TABLE channels ADD COLUMN enabled BOOLEAN NOT NULL DEFAULT 'true'; -ALTER TABLE channels ADD COLUMN comment TEXT; - -COMMIT; diff --git a/docs/schema-upgrade-1.27-1.28.sql b/docs/schema-upgrade-1.27-1.28.sql deleted file mode 100644 index a686d8b..0000000 --- a/docs/schema-upgrade-1.27-1.28.sql +++ /dev/null @@ -1,24 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.27 to 1.28 - - -BEGIN; - -ALTER TABLE permissions ADD COLUMN description TEXT; - -UPDATE permissions set description='Full administrator access. Perform all actions.' WHERE name = 'admin'; -UPDATE permissions set description='Create appliance builds - deprecated.' WHERE name = 'appliance'; -UPDATE permissions set description='Create a dist-repo.' WHERE name = 'dist-repo'; -UPDATE permissions set description='Add, remove, enable, disable hosts and channels.' WHERE name = 'host'; -UPDATE permissions set description='Start image tasks.' WHERE name = 'image'; -UPDATE permissions set description='Import image archives.' WHERE name = 'image-import'; -UPDATE permissions set description='Start livecd tasks.' WHERE name = 'livecd'; -UPDATE permissions set description='Import maven archives.' WHERE name = 'maven-import'; -UPDATE permissions set description='Manage repos: newRepo, repoExpire, repoDelete, repoProblem.' WHERE name = 'repo'; -UPDATE permissions set description='Import RPM signatures and write signed RPMs.' WHERE name = 'sign'; -UPDATE permissions set description='Manage packages in tags: add, block, remove, and clone tags.' WHERE name = 'tag'; -UPDATE permissions set description='Add, edit, and remove targets.' WHERE name = 'target'; -UPDATE permissions set description='The default hub policy rule for "vm" requires this permission to trigger Windows builds.' WHERE name = 'win-admin'; -UPDATE permissions set description='Import win archives.' WHERE name = 'win-import'; - -COMMIT; diff --git a/docs/schema-upgrade-1.28-1.29.sql b/docs/schema-upgrade-1.28-1.29.sql deleted file mode 100644 index 10fe8a1..0000000 --- a/docs/schema-upgrade-1.28-1.29.sql +++ /dev/null @@ -1,5 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.28 to 1.29 - - --- This version introduced no changes in db schema diff --git a/docs/schema-upgrade-1.29-1.30.sql b/docs/schema-upgrade-1.29-1.30.sql deleted file mode 100644 index 4ab6bc0..0000000 --- a/docs/schema-upgrade-1.29-1.30.sql +++ /dev/null @@ -1,19 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.29 to 1.30 - - -BEGIN; - -ALTER TABLE archivetypes ADD COLUMN compression_type TEXT; - -UPDATE archivetypes set compression_type='zip' WHERE name = 'jar'; -UPDATE archivetypes set compression_type='zip' WHERE name = 'zip'; -UPDATE archivetypes set compression_type='tar' WHERE name = 'tar'; - --- clean some unused old indices if they still exist --- https://pagure.io/koji/issue/3160 -DROP INDEX IF EXISTS image_listing_archives; -DROP INDEX IF EXISTS image_listing_rpms; -DROP INDEX IF EXISTS imageinfo_listing_rpms; - -COMMIT; diff --git a/docs/schema-upgrade-1.3-1.4.sql b/docs/schema-upgrade-1.3-1.4.sql deleted file mode 100644 index 3754ba2..0000000 --- a/docs/schema-upgrade-1.3-1.4.sql +++ /dev/null @@ -1,267 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.3 to 1.4 - -BEGIN; - --- First the simple stuff. A pair of new host fields. -ALTER TABLE host ADD COLUMN description TEXT; -ALTER TABLE host ADD COLUMN comment TEXT; --- ...and a new field for tasks -ALTER TABLE task ADD COLUMN start_time TIMESTAMP; - - --- new standard permissions and channels -INSERT INTO permissions (name) VALUES ('maven-import'); -INSERT INTO permissions (name) VALUES ('appliance'); - -INSERT INTO channels (name) VALUES ('maven'); -INSERT INTO channels (name) VALUES ('appliance'); - - --- extensions for maven support -ALTER TABLE tag_config ADD COLUMN maven_support BOOLEAN NOT NULL DEFAULT FALSE; -ALTER TABLE tag_config ADD COLUMN maven_include_all BOOLEAN NOT NULL DEFAULT FALSE; - -CREATE TABLE maven_builds ( - build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id), - group_id TEXT NOT NULL, - artifact_id TEXT NOT NULL, - version TEXT NOT NULL -) WITHOUT OIDS; - -CREATE TABLE archivetypes ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT NOT NULL UNIQUE, - description TEXT NOT NULL, - extensions TEXT NOT NULL -) WITHOUT OIDS; - -insert into archivetypes (name, description, extensions) values ('jar', 'Jar file', 'jar war rar ear'); -insert into archivetypes (name, description, extensions) values ('zip', 'Zip archive', 'zip'); -insert into archivetypes (name, description, extensions) values ('pom', 'Maven Project Object Management file', 'pom'); -insert into archivetypes (name, description, extensions) values ('tar', 'Tar file', 'tar tar.gz tar.bz2'); -insert into archivetypes (name, description, extensions) values ('xml', 'XML file', 'xml'); - -CREATE TABLE archiveinfo ( - id SERIAL NOT NULL PRIMARY KEY, - type_id INTEGER NOT NULL REFERENCES archivetypes (id), - build_id INTEGER NOT NULL REFERENCES build (id), - buildroot_id INTEGER REFERENCES buildroot (id), - filename TEXT NOT NULL, - size INTEGER NOT NULL, - md5sum TEXT NOT NULL -) WITHOUT OIDS; -CREATE INDEX archiveinfo_build_idx ON archiveinfo (build_id); -CREATE INDEX archiveinfo_buildroot_idx on archiveinfo (buildroot_id); -CREATE INDEX archiveinfo_type_idx on archiveinfo (type_id); -CREATE INDEX archiveinfo_filename_idx on archiveinfo(filename); - -CREATE TABLE maven_archives ( - archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), - group_id TEXT NOT NULL, - artifact_id TEXT NOT NULL, - version TEXT NOT NULL -) WITHOUT OIDS; - -CREATE TABLE buildroot_archives ( - buildroot_id INTEGER NOT NULL REFERENCES buildroot (id), - archive_id INTEGER NOT NULL REFERENCES archiveinfo (id), - project_dep BOOLEAN NOT NULL, - PRIMARY KEY (buildroot_id, archive_id) -) WITHOUT OIDS; -CREATE INDEX buildroot_archives_archive_idx ON buildroot_archives (archive_id); - - - --- The rest updates all the versioned tables to track who did what - --- One issue with this is that we need to provide creator/revoker data --- for existing rows. Our approach is to create a disabled user to use --- for this named 'nobody'. The temporary function is merely a convenient --- way to reference the user we create. -INSERT INTO users (name, status, usertype) VALUES ('nobody', 1, 0); -CREATE FUNCTION pg_temp.user() returns INTEGER as $$ select id from users where name='nobody' $$ language SQL; --- If you would like to use an existing user instead, then: --- 1. comment out the users insert --- 2. edit the temporary function to look for the alternate user name - -SELECT 'Updating table user_perms'; - -ALTER TABLE user_perms ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE user_perms ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE user_perms SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE user_perms SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE user_perms ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE user_perms DROP CONSTRAINT active_revoke_sane; -ALTER TABLE user_perms ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table user_groups'; - -ALTER TABLE user_groups ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE user_groups ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE user_groups SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE user_groups SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE user_groups ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE user_groups DROP CONSTRAINT active_revoke_sane; -ALTER TABLE user_groups ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table tag_inheritance'; - -ALTER TABLE tag_inheritance ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE tag_inheritance ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE tag_inheritance SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE tag_inheritance SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE tag_inheritance ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE tag_inheritance DROP CONSTRAINT active_revoke_sane; -ALTER TABLE tag_inheritance ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table tag_config'; - -ALTER TABLE tag_config ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE tag_config ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE tag_config SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE tag_config SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE tag_config ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE tag_config DROP CONSTRAINT active_revoke_sane; -ALTER TABLE tag_config ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table build_target_config'; - -ALTER TABLE build_target_config ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE build_target_config ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE build_target_config SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE build_target_config SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE build_target_config ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE build_target_config DROP CONSTRAINT active_revoke_sane; -ALTER TABLE build_target_config ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table external_repo_config'; - -ALTER TABLE external_repo_config ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE external_repo_config ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE external_repo_config SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE external_repo_config SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE external_repo_config ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE external_repo_config DROP CONSTRAINT active_revoke_sane; -ALTER TABLE external_repo_config ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table tag_external_repos'; - -ALTER TABLE tag_external_repos ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE tag_external_repos ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE tag_external_repos SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE tag_external_repos SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE tag_external_repos ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE tag_external_repos DROP CONSTRAINT active_revoke_sane; -ALTER TABLE tag_external_repos ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table tag_listing'; - -ALTER TABLE tag_listing ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE tag_listing ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE tag_listing SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE tag_listing SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE tag_listing ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE tag_listing DROP CONSTRAINT active_revoke_sane; -ALTER TABLE tag_listing ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table tag_packages'; - -ALTER TABLE tag_packages ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE tag_packages ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE tag_packages SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE tag_packages SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE tag_packages ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE tag_packages DROP CONSTRAINT active_revoke_sane; -ALTER TABLE tag_packages ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table group_config'; - -ALTER TABLE group_config ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE group_config ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE group_config SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE group_config SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE group_config ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE group_config DROP CONSTRAINT active_revoke_sane; -ALTER TABLE group_config ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table group_req_listing'; - -ALTER TABLE group_req_listing ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE group_req_listing ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE group_req_listing SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE group_req_listing SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE group_req_listing ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE group_req_listing DROP CONSTRAINT active_revoke_sane; -ALTER TABLE group_req_listing ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - - -SELECT 'Updating table group_package_listing'; - -ALTER TABLE group_package_listing ADD COLUMN creator_id INTEGER REFERENCES users(id); -ALTER TABLE group_package_listing ADD COLUMN revoker_id INTEGER REFERENCES users(id); - -UPDATE group_package_listing SET creator_id=pg_temp.user() WHERE creator_id IS NULL; -UPDATE group_package_listing SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; - -ALTER TABLE group_package_listing ALTER COLUMN creator_id SET NOT NULL; -ALTER TABLE group_package_listing DROP CONSTRAINT active_revoke_sane; -ALTER TABLE group_package_listing ADD CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); - -COMMIT; diff --git a/docs/schema-upgrade-1.30-1.31.sql b/docs/schema-upgrade-1.30-1.31.sql deleted file mode 100644 index eee9e74..0000000 --- a/docs/schema-upgrade-1.30-1.31.sql +++ /dev/null @@ -1,17 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.30 to 1.31 - -BEGIN; - -- index for default search method for rpms, PG11+ can benefit from new include method - DO $$ - DECLARE version integer; - BEGIN - SELECT current_setting('server_version_num')::integer INTO version; - IF version >= 110000 THEN - EXECUTE 'CREATE INDEX rpminfo_filename ON rpminfo((name || ''-'' || version || ''-'' || release || ''.'' || arch || ''.rpm'')) INCLUDE (id);'; - ELSE - EXECUTE 'CREATE INDEX rpminfo_filename ON rpminfo((name || ''-'' || version || ''-'' || release || ''.'' || arch || ''.rpm''));'; - END IF; - END - $$; -COMMIT; diff --git a/docs/schema-upgrade-1.31-1.32.sql b/docs/schema-upgrade-1.31-1.32.sql deleted file mode 100644 index 2cf0cb3..0000000 --- a/docs/schema-upgrade-1.31-1.32.sql +++ /dev/null @@ -1,23 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.31 to 1.32 - -BEGIN; - - -- fix duplicate extension in archivetypes - UPDATE archivetypes SET extensions = 'vhdx.gz vhdx.xz' WHERE name = 'vhdx-compressed'; - - -- for tag if session is closed or not - ALTER TABLE sessions ADD COLUMN closed BOOLEAN NOT NULL DEFAULT FALSE; - ALTER TABLE sessions ADD CONSTRAINT no_closed_exclusive CHECK (closed IS FALSE OR "exclusive" IS NULL); - ALTER TABLE sessions DROP CONSTRAINT exclusive_expired_sane; - - -- track checksum of rpms - CREATE TABLE rpm_checksum ( - rpm_id INTEGER NOT NULL REFERENCES rpminfo(id), - sigkey TEXT NOT NULL, - checksum TEXT NOT NULL UNIQUE, - checksum_type SMALLINT NOT NULL, - PRIMARY KEY (rpm_id, sigkey, checksum_type) - ) WITHOUT OIDS; - CREATE INDEX rpm_checksum_rpm_id ON rpm_checksum(rpm_id); -COMMIT; diff --git a/docs/schema-upgrade-1.32-1.33.sql b/docs/schema-upgrade-1.32-1.33.sql deleted file mode 100644 index 9efb8d7..0000000 --- a/docs/schema-upgrade-1.32-1.33.sql +++ /dev/null @@ -1,15 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.32 to 1.33 - -BEGIN; - ALTER TABLE sessions ADD COLUMN renew_time TIMESTAMPTZ; - INSERT INTO archivetypes (name, description, extensions) VALUES ('checksum', 'Checksum file', 'sha256') ON CONFLICT DO NOTHING; - INSERT INTO archivetypes (name, description, extensions) VALUES ('changes', 'Kiwi changes file', 'changes.xz changes') ON CONFLICT DO NOTHING; - INSERT INTO archivetypes (name, description, extensions) VALUES ('packages', 'Kiwi packages listing', 'packages') ON CONFLICT DO NOTHING; - INSERT INTO archivetypes (name, description, extensions) VALUES ('verified', 'Kiwi verified package list', 'verified') ON CONFLICT DO NOTHING; - ALTER TABLE host ADD COLUMN update_time TIMESTAMPTZ; - CREATE TABLE locks ( - name TEXT NOT NULL PRIMARY KEY - ) WITHOUT OIDS; - INSERT INTO locks(name) VALUES('protonmsg-plugin'); -COMMIT; diff --git a/docs/schema-upgrade-1.4-1.5.sql b/docs/schema-upgrade-1.4-1.5.sql deleted file mode 100644 index ccc4432..0000000 --- a/docs/schema-upgrade-1.4-1.5.sql +++ /dev/null @@ -1,36 +0,0 @@ --- upgrade script to migrate the Koji database schema --- from version 1.4 to 1.5 - -BEGIN; - -INSERT INTO permissions (name) VALUES ('win-import'); -INSERT INTO permissions (name) VALUES ('win-admin'); - -INSERT INTO channels (name) VALUES ('vm'); - -insert into archivetypes (name, description, extensions) values ('spec', 'RPM spec file', 'spec'); -insert into archivetypes (name, description, extensions) values ('exe', 'Windows executable', 'exe'); -insert into archivetypes (name, description, extensions) values ('dll', 'Windows dynamic link library', 'dll'); -insert into archivetypes (name, description, extensions) values ('lib', 'Windows import library', 'lib'); -insert into archivetypes (name, description, extensions) values ('sys', 'Windows device driver', 'sys'); -insert into archivetypes (name, description, extensions) values ('inf', 'Windows driver information file', 'inf'); -insert into archivetypes (name, description, extensions) values ('cat', 'Windows catalog file', 'cat'); -insert into archivetypes (name, description, extensions) values ('msi', 'Windows Installer package', 'msi'); -insert into archivetypes (name, description, extensions) values ('pdb', 'Windows debug information', 'pdb'); -insert into archivetypes (name, description, extensions) values ('oem', 'Windows driver oem file', 'oem'); - --- flag to indicate that a build is a Windows build -CREATE TABLE win_builds ( - build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id), - platform TEXT NOT NULL -) WITHOUT OIDS; - --- Extended information about files built in Windows VMs -CREATE TABLE win_archives ( - archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), - relpath TEXT NOT NULL, - platforms TEXT NOT NULL, - flags TEXT -) WITHOUT OIDS; - -COMMIT WORK; diff --git a/docs/schema-upgrade-1.6-1.7.sql b/docs/schema-upgrade-1.6-1.7.sql deleted file mode 100644 index 614eb74..0000000 --- a/docs/schema-upgrade-1.6-1.7.sql +++ /dev/null @@ -1,25 +0,0 @@ -BEGIN; - -CREATE TABLE volume ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -) WITHOUT OIDS; - -INSERT INTO volume (id, name) VALUES (0, 'DEFAULT'); - -ALTER TABLE build ADD COLUMN volume_id INTEGER REFERENCES volume (id); -UPDATE build SET volume_id = 0; -ALTER TABLE build ALTER COLUMN volume_id SET NOT NULL; - -CREATE TABLE tag_updates ( - id SERIAL NOT NULL PRIMARY KEY, - tag_id INTEGER NOT NULL REFERENCES tag(id), - update_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - updater_id INTEGER NOT NULL REFERENCES users(id), - update_type INTEGER NOT NULL -) WITHOUT OIDS; - -CREATE INDEX tag_updates_by_tag ON tag_updates (tag_id); -CREATE INDEX tag_updates_by_event ON tag_updates (update_event); - -COMMIT; diff --git a/docs/schema-upgrade-1.7-1.8.sql b/docs/schema-upgrade-1.7-1.8.sql deleted file mode 100644 index 60f5c19..0000000 --- a/docs/schema-upgrade-1.7-1.8.sql +++ /dev/null @@ -1,47 +0,0 @@ --- schema migration from version 1.7 to 1.8 --- note: this update will require additional steps, please see the migration doc - -BEGIN; - - --- The following tables are now obsolete: --- imageinfo --- imageinfo_listing --- However, we cannot drop them until after we migrate the data - --- create new image tables -CREATE TABLE image_builds ( - build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id) -) WITHOUT OIDS; - -CREATE TABLE image_archives ( - archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), - arch VARCHAR(16) NOT NULL -) WITHOUT OIDS; - -CREATE TABLE image_listing ( - image_id INTEGER NOT NULL REFERENCES image_archives(archive_id), - rpm_id INTEGER NOT NULL REFERENCES rpminfo(id), - UNIQUE (image_id, rpm_id) -) WITHOUT OIDS; -CREATE INDEX image_listing_rpms on image_listing(rpm_id); - --- alter archiveinfo -ALTER TABLE archiveinfo ALTER COLUMN size TYPE BIGINT; -ALTER TABLE archiveinfo RENAME COLUMN md5sum TO checksum; -ALTER TABLE archiveinfo ADD COLUMN checksum_type INTEGER NOT NULL DEFAULT 0; -ALTER TABLE archiveinfo ALTER COLUMN checksum_type DROP DEFAULT; --- the main schema has no default for checksum_type --- this is just an easy way to populate the fields for the old entries - - - --- new archive types -insert into archivetypes (name, description, extensions) values ('iso', 'CD/DVD Image', 'iso'); -insert into archivetypes (name, description, extensions) values ('raw', 'Raw disk image', 'raw'); -insert into archivetypes (name, description, extensions) values ('qcow', 'QCOW image', 'qcow'); -insert into archivetypes (name, description, extensions) values ('qcow2', 'QCOW2 image', 'qcow2'); -insert into archivetypes (name, description, extensions) values ('vmx', 'VMX image', 'vmx'); -insert into archivetypes (name, description, extensions) values ('xsd', 'XML Schema Definition', 'xsd'); - -COMMIT; diff --git a/docs/schema-upgrade-1.8-1.9.sql b/docs/schema-upgrade-1.8-1.9.sql deleted file mode 100644 index 00e39c7..0000000 --- a/docs/schema-upgrade-1.8-1.9.sql +++ /dev/null @@ -1,16 +0,0 @@ - -BEGIN; - --- new archive types -insert into archivetypes (name, description, extensions) values ('vmdk', 'vSphere image', 'vmdk'); -insert into archivetypes (name, description, extensions) values ('ova', 'OVA image', 'ova'); -insert into archivetypes (name, description, extensions) values ('ks', 'Kickstart', 'ks'); -insert into archivetypes (name, description, extensions) values ('cfg', 'Configuration file', 'cfg'); - -COMMIT; - -BEGIN; --- it's harmless if this part fails. --- there shouldn't be any references to this, but keep it in a separate transaction just in case -delete from archivetypes where name = 'vmx'; -COMMIT; diff --git a/docs/schema-upgrade-1.9-1.10.sql b/docs/schema-upgrade-1.9-1.10.sql deleted file mode 100644 index b70698d..0000000 --- a/docs/schema-upgrade-1.9-1.10.sql +++ /dev/null @@ -1,50 +0,0 @@ - -BEGIN; - -INSERT INTO channels (name) VALUES ('image'); - - -CREATE TABLE tag_extra ( - tag_id INTEGER NOT NULL REFERENCES tag(id), - key TEXT NOT NULL, - value TEXT NOT NULL, -- TODO - move this to jsonb when we can --- versioned - see desc above - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, tag_id, key), - UNIQUE (tag_id, key, active) -) WITHOUT OIDS; - - -update archivetypes set extensions='jar war rar ear sar jdocbook jdocbook-style' where name='jar'; -update archivetypes set description='Zip file' where name='zip'; -update archivetypes set extensions='tar tar.gz tar.bz2 tar.xz' where name='tar'; -update archivetypes set description='Open Virtualization Archive' where name='ova'; - -insert into archivetypes (name, description, extensions) values ('vdi', 'VirtualBox Virtual Disk Image', 'vdi'); -insert into archivetypes (name, description, extensions) values ('aar', 'Binary distribution of an Android Library project', 'aar'); -insert into archivetypes (name, description, extensions) values ('apklib', 'Source distribution of an Android Library project', 'apklib'); -insert into archivetypes (name, description, extensions) values ('cab', 'Windows cabinet file', 'cab'); -insert into archivetypes (name, description, extensions) values ('dylib', 'OS X dynamic library', 'dylib'); -insert into archivetypes (name, description, extensions) values ('gem', 'Ruby gem', 'gem'); -insert into archivetypes (name, description, extensions) values ('ini', 'INI config file', 'ini'); -insert into archivetypes (name, description, extensions) values ('js', 'Javascript file', 'js'); -insert into archivetypes (name, description, extensions) values ('ldif', 'LDAP Data Interchange Format file', 'ldif'); -insert into archivetypes (name, description, extensions) values ('manifest', 'Runtime environment for .NET applications', 'manifest'); -insert into archivetypes (name, description, extensions) values ('msm', 'Windows merge module', 'msm'); -insert into archivetypes (name, description, extensions) values ('properties', 'Properties file', 'properties'); -insert into archivetypes (name, description, extensions) values ('sig', 'Signature file', 'sig signature'); -insert into archivetypes (name, description, extensions) values ('so', 'Shared library', 'so'); -insert into archivetypes (name, description, extensions) values ('txt', 'Text file', 'txt'); -insert into archivetypes (name, description, extensions) values ('vhd', 'Hyper-V image', 'vhd'); -insert into archivetypes (name, description, extensions) values ('wsf', 'Windows script file', 'wsf'); -insert into archivetypes (name, description, extensions) values ('box', 'Vagrant Box Image', 'box'); -insert into archivetypes (name, description, extensions) values ('raw-xz', 'xz compressed raw disk image', 'raw.xz'); - -COMMIT; diff --git a/docs/schema.sql b/docs/schema.sql deleted file mode 100644 index 5fa6a22..0000000 --- a/docs/schema.sql +++ /dev/null @@ -1,992 +0,0 @@ - --- vim:et:sw=8 - -BEGIN WORK; - --- We use the events table to sequence time --- in the event that the system clock rolls back, event_ids will retain proper sequencing -CREATE TABLE events ( - id SERIAL NOT NULL PRIMARY KEY, - time TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp() -) WITHOUT OIDS; - --- A function that creates an event and returns the id, used as DEFAULT value for versioned tables -CREATE FUNCTION get_event() RETURNS INTEGER AS ' - INSERT INTO events (time) VALUES (clock_timestamp()); - SELECT currval(''events_id_seq'')::INTEGER; -' LANGUAGE SQL; - --- A convenience function for converting events to timestamps, useful for --- quick queries where you want to avoid JOINs. -CREATE FUNCTION get_event_time(INTEGER) RETURNS TIMESTAMPTZ AS ' - SELECT time FROM events WHERE id=$1; -' LANGUAGE SQL; - --- this table is used to label events --- most events will be unlabeled, so keeping this separate saves space -CREATE TABLE event_labels ( - event_id INTEGER NOT NULL REFERENCES events(id), - label VARCHAR(255) UNIQUE NOT NULL -) WITHOUT OIDS; - - --- User and session data -CREATE TABLE users ( - id SERIAL NOT NULL PRIMARY KEY, - name VARCHAR(255) UNIQUE NOT NULL, - password VARCHAR(255), - status INTEGER NOT NULL, - usertype INTEGER NOT NULL -) WITHOUT OIDS; - -CREATE TABLE user_krb_principals ( - user_id INTEGER NOT NULL REFERENCES users(id), - krb_principal VARCHAR(255) NOT NULL UNIQUE, - PRIMARY KEY (user_id, krb_principal) -) WITHOUT OIDS; - -CREATE TABLE permissions ( - id SERIAL NOT NULL PRIMARY KEY, - name VARCHAR(50) UNIQUE NOT NULL, - description TEXT -) WITHOUT OIDS; - --- Some basic perms -INSERT INTO permissions (name, description) VALUES ('admin', 'Full administrator access. Perform all actions.'); -INSERT INTO permissions (name, description) VALUES ('appliance', 'Create appliance builds - deprecated.'); -INSERT INTO permissions (name, description) VALUES ('dist-repo', 'Create a dist-repo.'); -INSERT INTO permissions (name, description) VALUES ('host', 'Add, remove, enable, disable hosts and channels.'); -INSERT INTO permissions (name, description) VALUES ('image', 'Start image tasks.'); -INSERT INTO permissions (name, description) VALUES ('image-import', 'Import image archives.'); -INSERT INTO permissions (name, description) VALUES ('livecd', 'Start livecd tasks.'); -INSERT INTO permissions (name, description) VALUES ('maven-import', 'Import maven archives.'); -INSERT INTO permissions (name, description) VALUES ('repo', 'Manage repos: newRepo, repoExpire, repoDelete, repoProblem.'); -INSERT INTO permissions (name, description) VALUES ('sign', 'Import RPM signatures and write signed RPMs.'); -INSERT INTO permissions (name, description) VALUES ('tag', 'Manage packages in tags: add, block, remove, and clone tags.'); -INSERT INTO permissions (name, description) VALUES ('target', 'Add, edit, and remove targets.'); -INSERT INTO permissions (name, description) VALUES ('win-admin', 'The default hub policy rule for "vm" requires this permission to trigger Windows builds.'); -INSERT INTO permissions (name, description) VALUES ('win-import', 'Import win archives.'); - -CREATE TABLE user_perms ( - user_id INTEGER NOT NULL REFERENCES users(id), - perm_id INTEGER NOT NULL REFERENCES permissions(id), --- versioned - see VERSIONING - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, user_id, perm_id), - UNIQUE (user_id,perm_id,active) -) WITHOUT OIDS; - --- groups are represented as users w/ usertype=2 -CREATE TABLE user_groups ( - user_id INTEGER NOT NULL REFERENCES users(id), - group_id INTEGER NOT NULL REFERENCES users(id), --- versioned - see VERSIONING - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, user_id, group_id), - UNIQUE (user_id,group_id,active) -) WITHOUT OIDS; - --- a session can create subsessions, which are just new sessions whose --- 'master' field points back to the session. This field should --- always point to the top session. If the master session is expired, --- the all its subsessions should be expired as well. --- If a session is exclusive, it is the only session allowed for its --- user. The 'exclusive' field is either NULL or TRUE, never FALSE. This --- is so exclusivity can be enforced with a unique condition. -CREATE TABLE sessions ( - id SERIAL NOT NULL PRIMARY KEY, - user_id INTEGER NOT NULL REFERENCES users(id), - expired BOOLEAN NOT NULL DEFAULT FALSE, - master INTEGER REFERENCES sessions(id), - key VARCHAR(255), - authtype INTEGER, - hostip VARCHAR(255), - callnum INTEGER, - start_time TIMESTAMPTZ NOT NULL DEFAULT NOW(), - update_time TIMESTAMPTZ NOT NULL DEFAULT NOW(), - exclusive BOOLEAN CHECK (exclusive), - closed BOOLEAN NOT NULL DEFAULT FALSE, - renew_time TIMESTAMPTZ, - CONSTRAINT no_exclusive_subsessions CHECK ( - master IS NULL OR "exclusive" IS NULL), - CONSTRAINT no_closed_exclusive CHECK ( - closed IS FALSE OR "exclusive" IS NULL), - UNIQUE (user_id,exclusive) -) WITHOUT OIDS; -CREATE INDEX sessions_master ON sessions(master); -CREATE INDEX sessions_active_and_recent ON sessions(expired, master, update_time) WHERE (expired = FALSE AND master IS NULL); -CREATE INDEX sessions_expired ON sessions(expired); - --- Channels are used to limit which tasks are run on which machines. --- Each task is assigned to a channel and each host 'listens' on one --- or more channels. A host will only accept tasks for channels it is --- listening to. -CREATE TABLE channels ( - id SERIAL NOT NULL PRIMARY KEY, - name VARCHAR(128) UNIQUE NOT NULL, - description TEXT, - enabled BOOLEAN NOT NULL DEFAULT 'true', - comment TEXT -) WITHOUT OIDS; - --- create default channel -INSERT INTO channels (name) VALUES ('default'); -INSERT INTO channels (name) VALUES ('createrepo'); -INSERT INTO channels (name) VALUES ('maven'); -INSERT INTO channels (name) VALUES ('livecd'); -INSERT INTO channels (name) VALUES ('appliance'); -INSERT INTO channels (name) VALUES ('vm'); -INSERT INTO channels (name) VALUES ('image'); -INSERT INTO channels (name) VALUES ('livemedia'); - --- Here we track the build machines --- each host has an entry in the users table also --- capacity: the hosts weighted task capacity -CREATE TABLE host ( - id SERIAL NOT NULL PRIMARY KEY, - user_id INTEGER NOT NULL REFERENCES users (id), - name VARCHAR(128) UNIQUE NOT NULL, - update_time TIMESTAMPTZ, - task_load FLOAT CHECK (NOT task_load < 0) NOT NULL DEFAULT 0.0, - ready BOOLEAN NOT NULL DEFAULT 'false' -) WITHOUT OIDS; - -CREATE TABLE host_config ( - host_id INTEGER NOT NULL REFERENCES host(id), - arches TEXT, - capacity FLOAT CHECK (capacity > 1) NOT NULL DEFAULT 2.0, - description TEXT, - comment TEXT, - enabled BOOLEAN NOT NULL DEFAULT 'true', --- versioned - see desc above - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, host_id), - UNIQUE (host_id, active) -) WITHOUT OIDS; -CREATE INDEX host_config_by_active_and_enabled ON host_config(active, enabled); - -CREATE TABLE host_channels ( - host_id INTEGER NOT NULL REFERENCES host(id), - channel_id INTEGER NOT NULL REFERENCES channels(id), --- versioned - see desc above - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, host_id, channel_id), - UNIQUE (host_id, channel_id, active) -) WITHOUT OIDS; - - --- tasks are pretty general and may refer to all sorts of jobs, not --- just package builds. --- tasks may spawn subtasks (hence the parent field) --- top-level tasks have NULL parent --- the request and result fields are xmlrpc data. --- this means each task is effectively an xmlrpc call, using this table as --- the medium. --- the host_id field indicates which host is running the task. This field --- is used to lock the task. --- weight: the weight of the task (vs. host capacity) --- label: this field is used to label subtasks. top-level tasks will not --- have a label. some subtasks may be unlabeled. labels are used in task --- failover to prevent duplication of work. -CREATE TABLE task ( - id SERIAL NOT NULL PRIMARY KEY, - state INTEGER, - create_time TIMESTAMPTZ NOT NULL DEFAULT NOW(), - start_time TIMESTAMPTZ, - completion_time TIMESTAMPTZ, - channel_id INTEGER NOT NULL REFERENCES channels(id), - host_id INTEGER REFERENCES host (id), - parent INTEGER REFERENCES task (id), - label VARCHAR(255), - waiting BOOLEAN, - awaited BOOLEAN, - owner INTEGER REFERENCES users(id) NOT NULL, - method TEXT, - request TEXT, - result TEXT, - eta INTEGER, - arch VARCHAR(16) NOT NULL, - priority INTEGER, - weight FLOAT CHECK (NOT weight < 0) NOT NULL DEFAULT 1.0, - CONSTRAINT parent_label_sane CHECK ( - parent IS NOT NULL OR label IS NULL), - UNIQUE (parent,label) -) WITHOUT OIDS; - -CREATE INDEX task_by_state ON task (state); --- CREATE INDEX task_by_parent ON task (parent); (unique condition creates similar index) -CREATE INDEX task_by_host ON task (host_id); -CREATE INDEX task_by_no_parent_state_method ON task(parent, state, method) WHERE parent IS NULL; - - --- by package, we mean srpm --- we mean the package in general, not an individual build -CREATE TABLE package ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -) WITHOUT OIDS; - --- CREATE INDEX package_by_name ON package (name); --- (implicitly created by unique constraint) - - -CREATE TABLE volume ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -) WITHOUT OIDS; - -INSERT INTO volume (id, name) VALUES (0, 'DEFAULT'); - --- data for content generators -CREATE TABLE content_generator ( - id SERIAL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -) WITHOUT OIDS; - --- here we track the built packages --- this is at the srpm level, since builds are by srpm --- see rpminfo for isolated packages --- even though we track epoch, we demand that N-V-R be unique --- task_id: a reference to the task creating the build, may be --- null, or may point to a deleted task. -CREATE TABLE build ( - id SERIAL NOT NULL PRIMARY KEY, - volume_id INTEGER NOT NULL REFERENCES volume (id), - pkg_id INTEGER NOT NULL REFERENCES package (id) DEFERRABLE, - version TEXT NOT NULL, - release TEXT NOT NULL, - epoch INTEGER, - source TEXT, - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - start_time TIMESTAMPTZ, - completion_time TIMESTAMPTZ, - state INTEGER NOT NULL, - task_id INTEGER REFERENCES task (id), - owner INTEGER NOT NULL REFERENCES users (id), - cg_id INTEGER REFERENCES content_generator(id), - extra TEXT, - CONSTRAINT build_pkg_ver_rel UNIQUE (pkg_id, version, release), - CONSTRAINT completion_sane CHECK ((state = 0 AND completion_time IS NULL) OR - (state != 0 AND completion_time IS NOT NULL)) -) WITHOUT OIDS; - -CREATE INDEX build_by_pkg_id ON build (pkg_id); -CREATE INDEX build_completion ON build(completion_time); - - -CREATE TABLE btype ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -) WITHOUT OIDS; - - --- legacy build types -INSERT INTO btype(name) VALUES ('rpm'); -INSERT INTO btype(name) VALUES ('maven'); -INSERT INTO btype(name) VALUES ('win'); -INSERT INTO btype(name) VALUES ('image'); - - -CREATE TABLE build_types ( - build_id INTEGER NOT NULL REFERENCES build(id), - btype_id INTEGER NOT NULL REFERENCES btype(id), - PRIMARY KEY (build_id, btype_id) -) WITHOUT OIDS; - - --- Note: some of these CREATEs may seem a little out of order. This is done to keep --- the references sane. - -CREATE TABLE tag ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -) WITHOUT OIDS; - --- CREATE INDEX tag_by_name ON tag (name); --- (implicitly created by unique constraint) - - --- VERSIONING --- Several tables are versioned with the following scheme. Since this --- is the first, here is the explanation of how it works. --- The versioning fields are: create_event, revoke_event, and active --- The active field is either True or NULL, it is never False! --- The create_event and revoke_event fields refer to the event table --- A version is active if active is not NULL --- (an active version also has NULL revoke_event.) --- A UNIQUE condition can incorporate the 'active' field, making it --- apply only to the active versions. --- When a version is made inactive (revoked): --- revoke_event is set --- active is set to NULL --- Query for current data with WHERE active is not NULL --- (should be same as WHERE revoke_event is NULL) --- Query for data at event e with WHERE create_event <= e AND e < revoke_event -CREATE TABLE tag_inheritance ( - tag_id INTEGER NOT NULL REFERENCES tag(id), - parent_id INTEGER NOT NULL REFERENCES tag(id), - priority INTEGER NOT NULL, - maxdepth INTEGER, - intransitive BOOLEAN NOT NULL DEFAULT 'false', - noconfig BOOLEAN NOT NULL DEFAULT 'false', - pkg_filter TEXT, --- versioned - see desc above - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, tag_id, priority), - UNIQUE (tag_id,priority,active), - UNIQUE (tag_id,parent_id,active) -) WITHOUT OIDS; - -CREATE INDEX tag_inheritance_by_parent ON tag_inheritance (parent_id); - --- XXX - need more config options listed here --- perm_id: the permission that is required to apply the tag. can be NULL --- -CREATE TABLE tag_config ( - tag_id INTEGER NOT NULL REFERENCES tag(id), - arches TEXT, - perm_id INTEGER REFERENCES permissions(id), - locked BOOLEAN NOT NULL DEFAULT 'false', - maven_support BOOLEAN NOT NULL DEFAULT FALSE, - maven_include_all BOOLEAN NOT NULL DEFAULT FALSE, --- versioned - see desc above - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, tag_id), - UNIQUE (tag_id,active) -) WITHOUT OIDS; - -CREATE TABLE tag_extra ( - tag_id INTEGER NOT NULL REFERENCES tag(id), - key TEXT NOT NULL, - value TEXT, --- versioned - see desc above - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, tag_id, key), - UNIQUE (tag_id, key, active) -) WITHOUT OIDS; - --- the tag_updates table provides a mechanism to indicate changes relevant to tag --- that are not reflected in a versioned table. For example: builds changing volumes, --- changes to external repo content, additional rpms imported to an existing build -CREATE TABLE tag_updates ( - id SERIAL NOT NULL PRIMARY KEY, - tag_id INTEGER NOT NULL REFERENCES tag(id), - update_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - updater_id INTEGER NOT NULL REFERENCES users(id), - update_type INTEGER NOT NULL -) WITHOUT OIDS; - -CREATE INDEX tag_updates_by_tag ON tag_updates (tag_id); -CREATE INDEX tag_updates_by_event ON tag_updates (update_event); - --- a build target tells the system where to build the package --- and how to tag it afterwards. -CREATE TABLE build_target ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -) WITHOUT OIDS; - - -CREATE TABLE build_target_config ( - build_target_id INTEGER NOT NULL REFERENCES build_target(id), - build_tag INTEGER NOT NULL REFERENCES tag(id), - dest_tag INTEGER NOT NULL REFERENCES tag(id), --- versioned - see desc above - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, build_target_id), - UNIQUE (build_target_id,active) -) WITHOUT OIDS; - - --- track repos -CREATE TABLE repo ( - id SERIAL NOT NULL PRIMARY KEY, - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - tag_id INTEGER NOT NULL REFERENCES tag(id), - state INTEGER, - dist BOOLEAN DEFAULT 'false', - task_id INTEGER NULL REFERENCES task(id) -) WITHOUT OIDS; - --- external yum repos -create table external_repo ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT UNIQUE NOT NULL -); --- fake repo id for internal stuff (needed for unique index) -INSERT INTO external_repo (id, name) VALUES (0, 'INTERNAL'); - -CREATE TABLE external_repo_config ( - external_repo_id INTEGER NOT NULL REFERENCES external_repo(id), - url TEXT NOT NULL, --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, external_repo_id), - UNIQUE (external_repo_id, active) -) WITHOUT OIDS; - -CREATE TABLE tag_external_repos ( - tag_id INTEGER NOT NULL REFERENCES tag(id), - external_repo_id INTEGER NOT NULL REFERENCES external_repo(id), - priority INTEGER NOT NULL, - merge_mode TEXT NOT NULL DEFAULT 'koji', - arches TEXT, --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, tag_id, priority), - UNIQUE (tag_id, priority, active), - UNIQUE (tag_id, external_repo_id, active) -); - -CREATE TABLE cg_users ( - cg_id INTEGER NOT NULL REFERENCES content_generator (id), - user_id INTEGER NOT NULL REFERENCES users (id), --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, cg_id, user_id), - UNIQUE (cg_id, user_id, active) -) WITHOUT OIDS; - -CREATE TABLE build_reservations ( - build_id INTEGER NOT NULL REFERENCES build(id), - token VARCHAR(64), - created TIMESTAMPTZ NOT NULL, - PRIMARY KEY (build_id) -) WITHOUT OIDS; -CREATE INDEX build_reservations_created ON build_reservations(created); - --- here we track the buildroots on the machines -CREATE TABLE buildroot ( - id SERIAL NOT NULL PRIMARY KEY, - br_type INTEGER NOT NULL, - cg_id INTEGER REFERENCES content_generator (id), - cg_version TEXT, - CONSTRAINT cg_sane CHECK ( - (cg_id IS NULL AND cg_version IS NULL) - OR (cg_id IS NOT NULL AND cg_version IS NOT NULL)), - container_type TEXT, - container_arch TEXT, - CONSTRAINT container_sane CHECK ( - (container_type IS NULL AND container_arch IS NULL) - OR (container_type IS NOT NULL AND container_arch IS NOT NULL)), - host_os TEXT, - host_arch TEXT, - extra TEXT -) WITHOUT OIDS; - -CREATE TABLE standard_buildroot ( - buildroot_id INTEGER NOT NULL PRIMARY KEY REFERENCES buildroot(id), - host_id INTEGER NOT NULL REFERENCES host(id), - repo_id INTEGER NOT NULL REFERENCES repo (id), - task_id INTEGER NOT NULL REFERENCES task (id), - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - retire_event INTEGER, - state INTEGER -) WITHOUT OIDS; - -CREATE TABLE buildroot_tools_info ( - buildroot_id INTEGER NOT NULL REFERENCES buildroot(id), - tool TEXT NOT NULL, - version TEXT NOT NULL, - PRIMARY KEY (buildroot_id, tool) -) WITHOUT OIDS; - - --- track spun images (livecds, installation, VMs...) -CREATE TABLE image_builds ( - build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id) -) WITHOUT OIDS; - --- this table associates tags with builds. an entry here tags a package -CREATE TABLE tag_listing ( - build_id INTEGER NOT NULL REFERENCES build (id), - tag_id INTEGER NOT NULL REFERENCES tag (id), --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, build_id, tag_id), - UNIQUE (build_id,tag_id,active) -) WITHOUT OIDS; -CREATE INDEX tag_listing_tag_id_key ON tag_listing(tag_id); - --- this is a per-tag list of packages, with some extra info --- so this allows you to explicitly state which packages belong where --- (as opposed to beehive where this can only be done at the collection level) --- these are packages in general, not specific builds. --- this list limits which builds can be tagged with which tags --- if blocked is true, then the package is specifically not included. this --- prevents the package from being included via inheritance -CREATE TABLE tag_packages ( - package_id INTEGER NOT NULL REFERENCES package (id), - tag_id INTEGER NOT NULL REFERENCES tag (id), - blocked BOOLEAN NOT NULL DEFAULT FALSE, - extra_arches TEXT, --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, package_id, tag_id), - UNIQUE (package_id,tag_id,active) -) WITHOUT OIDS; -CREATE INDEX tag_packages_active_tag_id ON tag_packages(active, tag_id); -CREATE INDEX tag_packages_create_event ON tag_packages(create_event); -CREATE INDEX tag_packages_revoke_event ON tag_packages(revoke_event); - -CREATE TABLE tag_package_owners ( - package_id INTEGER NOT NULL REFERENCES package(id), - tag_id INTEGER NOT NULL REFERENCES tag (id), - owner INTEGER NOT NULL REFERENCES users(id), --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, package_id, tag_id), - UNIQUE (package_id,tag_id,active) -) WITHOUT OIDS; - --- package groups (per tag). used for generating comps for the tag repos -CREATE TABLE groups ( - id SERIAL NOT NULL PRIMARY KEY, - name VARCHAR(50) UNIQUE NOT NULL - -- corresponds to the id field in a comps group -) WITHOUT OIDS; - --- if blocked is true, then the group is specifically not included. this --- prevents the group from being included via inheritance -CREATE TABLE group_config ( - group_id INTEGER NOT NULL REFERENCES groups (id), - tag_id INTEGER NOT NULL REFERENCES tag (id), - blocked BOOLEAN NOT NULL DEFAULT FALSE, - exported BOOLEAN DEFAULT TRUE, - display_name TEXT NOT NULL, - is_default BOOLEAN, - uservisible BOOLEAN, - description TEXT, - langonly TEXT, - biarchonly BOOLEAN, --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, group_id, tag_id), - UNIQUE (group_id,tag_id,active) -) WITHOUT OIDS; - -CREATE TABLE group_req_listing ( - group_id INTEGER NOT NULL REFERENCES groups (id), - tag_id INTEGER NOT NULL REFERENCES tag (id), - req_id INTEGER NOT NULL REFERENCES groups (id), - blocked BOOLEAN NOT NULL DEFAULT FALSE, - type VARCHAR(25), - is_metapkg BOOLEAN NOT NULL DEFAULT FALSE, --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, group_id, tag_id, req_id), - UNIQUE (group_id,tag_id,req_id,active) -) WITHOUT OIDS; - --- if blocked is true, then the package is specifically not included. this --- prevents the package from being included in the group via inheritance --- package refers to an rpm name, not necessarily an srpm name (so it does --- not reference the package table). -CREATE TABLE group_package_listing ( - group_id INTEGER NOT NULL REFERENCES groups (id), - tag_id INTEGER NOT NULL REFERENCES tag (id), - package TEXT, - blocked BOOLEAN NOT NULL DEFAULT FALSE, - type VARCHAR(25) NOT NULL, - basearchonly BOOLEAN, - requires TEXT, --- versioned - see earlier description of versioning - create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), - revoke_event INTEGER REFERENCES events(id), - creator_id INTEGER NOT NULL REFERENCES users(id), - revoker_id INTEGER REFERENCES users(id), - active BOOLEAN DEFAULT 'true' CHECK (active), - CONSTRAINT active_revoke_sane CHECK ( - (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) - OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), - PRIMARY KEY (create_event, group_id, tag_id, package), - UNIQUE (group_id,tag_id,package,active) -) WITHOUT OIDS; - --- rpminfo tracks individual rpms (incl srpms) --- buildroot_id can be NULL (for externally built packages) --- even though we track epoch, we demand that N-V-R.A be unique --- we don't store filename b/c filename should be N-V-R.A.rpm -CREATE TABLE rpminfo ( - id SERIAL NOT NULL PRIMARY KEY, - build_id INTEGER REFERENCES build (id), - buildroot_id INTEGER REFERENCES buildroot (id), - name TEXT NOT NULL, - version TEXT NOT NULL, - release TEXT NOT NULL, - epoch INTEGER, - arch VARCHAR(16) NOT NULL, - external_repo_id INTEGER NOT NULL REFERENCES external_repo(id), - payloadhash TEXT NOT NULL, - size BIGINT NOT NULL, - buildtime BIGINT NOT NULL, - metadata_only BOOLEAN NOT NULL DEFAULT FALSE, - extra TEXT, - CONSTRAINT rpminfo_unique_nvra UNIQUE (name,version,release,arch,external_repo_id) -) WITHOUT OIDS; -CREATE INDEX rpminfo_build ON rpminfo(build_id); --- index for default search method for rpms, PG11+ can benefit from new include method -DO $$ - DECLARE version integer; - BEGIN - SELECT current_setting('server_version_num')::integer INTO version; - IF version >= 110000 THEN - EXECUTE 'CREATE INDEX rpminfo_filename ON rpminfo((name || ''-'' || version || ''-'' || release || ''.'' || arch || ''.rpm'')) INCLUDE (id);'; - ELSE - EXECUTE 'CREATE INDEX rpminfo_filename ON rpminfo((name || ''-'' || version || ''-'' || release || ''.'' || arch || ''.rpm''));'; - END IF; - END -$$; - --- sighash is the checksum of the signature header -CREATE TABLE rpmsigs ( - rpm_id INTEGER NOT NULL REFERENCES rpminfo (id), - sigkey TEXT NOT NULL, - sighash TEXT NOT NULL, - CONSTRAINT rpmsigs_no_resign UNIQUE (rpm_id, sigkey) -) WITHOUT OIDS; - --- buildroot_listing needs to be created after rpminfo so it can reference it -CREATE TABLE buildroot_listing ( - buildroot_id INTEGER NOT NULL REFERENCES buildroot(id), - rpm_id INTEGER NOT NULL REFERENCES rpminfo(id), - is_update BOOLEAN NOT NULL DEFAULT FALSE, - UNIQUE (buildroot_id,rpm_id) -) WITHOUT OIDS; -CREATE INDEX buildroot_listing_rpms ON buildroot_listing(rpm_id); - -CREATE TABLE build_notifications ( - id SERIAL NOT NULL PRIMARY KEY, - user_id INTEGER NOT NULL REFERENCES users (id), - package_id INTEGER REFERENCES package (id), - tag_id INTEGER REFERENCES tag (id), - success_only BOOLEAN NOT NULL DEFAULT FALSE, - email TEXT NOT NULL -) WITHOUT OIDS; - -CREATE TABLE build_notifications_block ( - id SERIAL NOT NULL PRIMARY KEY, - user_id INTEGER NOT NULL REFERENCES users (id), - package_id INTEGER REFERENCES package (id), - tag_id INTEGER REFERENCES tag (id) -) WITHOUT OIDS; - -GRANT SELECT ON build, package, task, tag, -tag_listing, tag_config, tag_inheritance, tag_packages, -rpminfo TO PUBLIC; - --- example code to add initial admins --- insert into users (name, usertype, status, krb_principal) values ('admin', 0, 0, 'admin@EXAMPLE.COM'); --- insert into user_perms (user_id, perm_id) --- select users.id, permissions.id from users, permissions --- where users.name in ('admin') --- and permissions.name = 'admin'; - --- Schema additions for multiplatform support - --- we need to track some additional metadata about Maven builds -CREATE TABLE maven_builds ( - build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id), - group_id TEXT NOT NULL, - artifact_id TEXT NOT NULL, - version TEXT NOT NULL -) WITHOUT OIDS; - --- Windows-specific build information -CREATE TABLE win_builds ( - build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id), - platform TEXT NOT NULL -) WITHOUT OIDS; - --- Even though we call this archiveinfo, we can probably use it for --- any filetype output by a build process. In general they will be --- archives (.zip, .jar, .tar.gz) but could also be installer executables (.exe) -CREATE TABLE archivetypes ( - id SERIAL NOT NULL PRIMARY KEY, - name TEXT NOT NULL UNIQUE, - description TEXT NOT NULL, - extensions TEXT NOT NULL, - compression_type TEXT -) WITHOUT OIDS; - -INSERT INTO archivetypes (name, description, extensions, compression_type) VALUES ('jar', 'Jar file', 'jar war rar ear sar jdocbook jdocbook-style', 'zip'); -INSERT INTO archivetypes (name, description, extensions, compression_type) VALUES ('zip', 'Zip file', 'zip', 'zip'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('pom', 'Maven Project Object Management file', 'pom'); -INSERT INTO archivetypes (name, description, extensions, compression_type) VALUES ('tar', 'Tar file', 'tar tar.gz tar.bz2 tar.xz tgz', 'tar'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('xml', 'XML file', 'xml'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('xmlcompressed', 'Compressed XML file', 'xml.gz xml.bz2 xml.xz'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('xsd', 'XML Schema Definition', 'xsd'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('spec', 'RPM spec file', 'spec'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('exe', 'Windows executable', 'exe'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('dll', 'Windows dynamic link library', 'dll'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('lib', 'Windows import library', 'lib'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('sys', 'Windows device driver', 'sys'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('inf', 'Windows driver information file', 'inf'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('cat', 'Windows catalog file', 'cat'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('msi', 'Windows Installer package', 'msi'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('pdb', 'Windows debug information', 'pdb'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('oem', 'Windows driver oem file', 'oem'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('iso', 'CD/DVD Image', 'iso'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('raw', 'Raw disk image', 'raw'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('qcow', 'QCOW image', 'qcow'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('qcow2', 'QCOW2 image', 'qcow2'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('vmdk', 'vSphere image', 'vmdk'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('ova', 'Open Virtualization Archive', 'ova'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('ks', 'Kickstart', 'ks'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('cfg', 'Configuration file', 'cfg'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('vdi', 'VirtualBox Virtual Disk Image', 'vdi'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('aar', 'Binary distribution of an Android Library project', 'aar'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('apklib', 'Source distribution of an Android Library project', 'apklib'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('cab', 'Windows cabinet file', 'cab'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('dylib', 'OS X dynamic library', 'dylib'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('gem', 'Ruby gem', 'gem'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('ini', 'INI config file', 'ini'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('js', 'Javascript file', 'js'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('ldif', 'LDAP Data Interchange Format file', 'ldif'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('manifest', 'Runtime environment for .NET applications', 'manifest'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('msm', 'Windows merge module', 'msm'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('properties', 'Properties file', 'properties'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('sig', 'Signature file', 'sig signature'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('so', 'Shared library', 'so'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('txt', 'Text file', 'txt'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('vhd', 'Hyper-V image', 'vhd'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('vhdx', 'Hyper-V Virtual Hard Disk v2 image', 'vhdx'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('wsf', 'Windows script file', 'wsf'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('box', 'Vagrant Box Image', 'box'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('raw-xz', 'xz compressed raw disk image', 'raw.xz'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('json', 'JSON data', 'json'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('key', 'Key file', 'key'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('dot', 'DOT graph description', 'dot gv'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('groovy', 'Groovy script file', 'groovy gvy'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('batch', 'Batch file', 'bat'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('shell', 'Shell script', 'sh'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('rc', 'Resource file', 'rc'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('wsdl', 'Web Services Description Language', 'wsdl'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('obr', 'OSGi Bundle Repository', 'obr'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('liveimg-squashfs', 'liveimg compatible squashfs image', 'liveimg.squashfs'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('tlb', 'OLE type library file', 'tlb'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('jnilib', 'Java Native Interface library', 'jnilib'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('yaml', 'YAML Ain''t Markup Language', 'yaml yml'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('xjb', 'JAXB(Java Architecture for XML Binding) Binding Customization File', 'xjb'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('raw-gz', 'GZIP compressed raw disk image', 'raw.gz'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('qcow2-compressed', 'Compressed QCOW2 image', 'qcow2.gz qcow2.xz'); --- add compressed iso-compressed, vhd-compressed, vhdx-compressed, and vmdk-compressed: From schema-upgrade-1.18-1.19 -INSERT INTO archivetypes (name, description, extensions) VALUES ('iso-compressed', 'Compressed iso image', 'iso.gz iso.xz'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('vhd-compressed', 'Compressed VHD image', 'vhd.gz vhd.xz'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('vhdx-compressed', 'Compressed VHDx image', 'vhdx.gz vhdx.xz'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('vmdk-compressed', 'Compressed VMDK image', 'vmdk.gz vmdk.xz'); --- add kernel-image and imitramfs: From schema-upgrade-1.18-1.19 -INSERT INTO archivetypes (name, description, extensions) VALUES ('kernel-image', 'Kernel BZ2 Image', 'vmlinuz vmlinuz.gz vmlinuz.xz'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('initramfs', 'Compressed Initramfs Image', 'img'); --- kiwi plugin -INSERT INTO archivetypes (name, description, extensions) VALUES ('checksum', 'Checksum file', 'sha256'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('changes', 'Kiwi changes file', 'changes.xz changes'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('packages', 'Kiwi packages listing', 'packages'); -INSERT INTO archivetypes (name, description, extensions) VALUES ('verified', 'Kiwi verified package list', 'verified'); - - --- Do we want to enforce a constraint that a build can only generate one --- archive with a given name? -CREATE TABLE archiveinfo ( - id SERIAL NOT NULL PRIMARY KEY, - type_id INTEGER NOT NULL REFERENCES archivetypes (id), - btype_id INTEGER REFERENCES btype(id), - -- ^ TODO add NOT NULL - build_id INTEGER NOT NULL REFERENCES build (id), - buildroot_id INTEGER REFERENCES buildroot (id), - filename TEXT NOT NULL, - size BIGINT NOT NULL, - checksum TEXT NOT NULL, - checksum_type INTEGER NOT NULL, - metadata_only BOOLEAN NOT NULL DEFAULT FALSE, - extra TEXT -) WITHOUT OIDS; -CREATE INDEX archiveinfo_build_idx ON archiveinfo (build_id); -CREATE INDEX archiveinfo_buildroot_idx on archiveinfo (buildroot_id); -CREATE INDEX archiveinfo_type_idx on archiveinfo (type_id); -CREATE INDEX archiveinfo_filename_idx on archiveinfo(filename); - -CREATE TABLE maven_archives ( - archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), - group_id TEXT NOT NULL, - artifact_id TEXT NOT NULL, - version TEXT NOT NULL -) WITHOUT OIDS; - -CREATE TABLE image_archives ( - archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), - arch VARCHAR(16) NOT NULL -) WITHOUT OIDS; - --- tracks the rpm contents of an image or other archive -CREATE TABLE archive_rpm_components ( - archive_id INTEGER NOT NULL REFERENCES archiveinfo(id), - rpm_id INTEGER NOT NULL REFERENCES rpminfo(id), - UNIQUE (archive_id, rpm_id) -) WITHOUT OIDS; -CREATE INDEX rpm_components_idx on archive_rpm_components(rpm_id); - --- track the archive contents of an image or other archive -CREATE TABLE archive_components ( - archive_id INTEGER NOT NULL REFERENCES archiveinfo(id), - component_id INTEGER NOT NULL REFERENCES archiveinfo(id), - UNIQUE (archive_id, component_id) -) WITHOUT OIDS; -CREATE INDEX archive_components_idx on archive_components(component_id); - - -CREATE TABLE buildroot_archives ( - buildroot_id INTEGER NOT NULL REFERENCES buildroot (id), - archive_id INTEGER NOT NULL REFERENCES archiveinfo (id), - project_dep BOOLEAN NOT NULL, - PRIMARY KEY (buildroot_id, archive_id) -) WITHOUT OIDS; -CREATE INDEX buildroot_archives_archive_idx ON buildroot_archives (archive_id); - --- Extended information about files built in Windows VMs -CREATE TABLE win_archives ( - archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), - relpath TEXT NOT NULL, - platforms TEXT NOT NULL, - flags TEXT -) WITHOUT OIDS; - - --- Message queue for the protonmsg plugin -CREATE TABLE proton_queue ( - id SERIAL PRIMARY KEY, - created_ts TIMESTAMPTZ DEFAULT NOW(), - address TEXT NOT NULL, - props JSON NOT NULL, - body JSON NOT NULL -) WITHOUT OIDS; - --- track checksum of rpms -CREATE TABLE rpm_checksum ( - rpm_id INTEGER NOT NULL REFERENCES rpminfo(id), - sigkey TEXT NOT NULL, - checksum TEXT NOT NULL UNIQUE, - checksum_type SMALLINT NOT NULL, - PRIMARY KEY (rpm_id, sigkey, checksum_type) -) WITHOUT OIDS; -CREATE INDEX rpm_checksum_rpm_id ON rpm_checksum(rpm_id); - --- this table is used for locking, see db_lock() -CREATE TABLE locks ( - name TEXT NOT NULL PRIMARY KEY -) WITHOUT OIDS; -INSERT INTO locks(name) VALUES('protonmsg-plugin'); - -COMMIT WORK; diff --git a/koji.spec b/koji.spec index 2b0db5a..c973233 100644 --- a/koji.spec +++ b/koji.spec @@ -428,7 +428,7 @@ make DESTDIR=$RPM_BUILD_ROOT KOJI_MINIMAL=1 PYTHON=%{__python3} install popd %endif %if 0%{py3_support} > 1 -for D in kojihub builder plugins util www vm ; do +for D in kojihub builder plugins util www vm schemas ; do pushd $D make DESTDIR=$RPM_BUILD_ROOT PYTHON=%{__python3} install popd @@ -516,6 +516,7 @@ rm -rf $RPM_BUILD_ROOT %{python3_sitelib}/%{name} %{python3_sitelib}/%{name}-%{version}.*-info %{python3_sitelib}/koji_cli +%{_datadir}/koji/*.sql %endif %if 0%{py2_support} diff --git a/schemas/Makefile b/schemas/Makefile new file mode 100644 index 0000000..48d06da --- /dev/null +++ b/schemas/Makefile @@ -0,0 +1,18 @@ +BUILDDIR = build +SQLFILES = $(wildcard *.sql) +SQLDIR = /usr/share/koji + +clean: + rm -rf $(BUILDDIR)/* + +install: + @if [ "$(DESTDIR)" = "" ]; then \ + echo " "; \ + echo "ERROR: A destdir is required"; \ + exit 1; \ + fi + + mkdir -p $(DESTDIR)/$(SQLDIR) + for p in $(SQLFILES) ; do \ + install -p -m 644 $$p $(DESTDIR)/$(SQLDIR)/$$p; \ + done diff --git a/schemas/schema-update-cgen.sql b/schemas/schema-update-cgen.sql new file mode 100644 index 0000000..dd7c0f4 --- /dev/null +++ b/schemas/schema-update-cgen.sql @@ -0,0 +1,112 @@ +-- PLEASE READ +-- This was an interim schema update script for changes introduced after +-- 1.10.1. +-- You probably want schema-upgrade-1.10-1.11.sql instead of this + + +BEGIN; + +-- New tables + +SELECT statement_timestamp(), 'Creating new tables' as msg; + +CREATE TABLE content_generator ( + id SERIAL PRIMARY KEY, + name TEXT +) WITHOUT OIDS; + +CREATE TABLE cg_users ( + cg_id INTEGER NOT NULL REFERENCES content_generator (id), + user_id INTEGER NOT NULL REFERENCES users (id), +-- versioned + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, cg_id, user_id), + UNIQUE (cg_id, user_id, active) +) WITHOUT OIDS; + + +CREATE TABLE buildroot_tools_info ( + buildroot_id INTEGER NOT NULL REFERENCES buildroot(id), + tool TEXT NOT NULL, + version TEXT NOT NULL, + PRIMARY KEY (buildroot_id, tool) +) WITHOUT OIDS; + + +CREATE TABLE image_archive_listing ( + image_id INTEGER NOT NULL REFERENCES image_archives(archive_id), + archive_id INTEGER NOT NULL REFERENCES archiveinfo(id), + UNIQUE (image_id, archive_id) +) WITHOUT OIDS; +CREATE INDEX image_listing_archives on image_archive_listing(archive_id); + + +-- new columns -- + +select statement_timestamp(), 'Adding new columns' as msg; +ALTER TABLE build ADD COLUMN start_time TIMESTAMP; +ALTER TABLE build ADD COLUMN source TEXT; +ALTER TABLE build ADD COLUMN extra TEXT; +ALTER TABLE rpminfo ADD COLUMN metadata_only BOOLEAN NOT NULL DEFAULT FALSE; +ALTER TABLE rpminfo ADD COLUMN extra TEXT; +ALTER TABLE archiveinfo ADD COLUMN metadata_only BOOLEAN NOT NULL DEFAULT FALSE; +ALTER TABLE archiveinfo ADD COLUMN extra TEXT; + + +-- the more complicated stuff + +SELECT statement_timestamp(), 'Copying buildroot to standard_buildroot' as msg; +CREATE TABLE standard_buildroot AS SELECT id,host_id,repo_id,task_id,create_event,retire_event,state from buildroot; +-- doing it this way and fixing up after is *much* faster than creating the empty table +-- and using insert..select to populate + +SELECT statement_timestamp(), 'Fixing up standard_buildroot table' as msg; +ALTER TABLE standard_buildroot RENAME id TO buildroot_id; +ALTER TABLE standard_buildroot ALTER COLUMN buildroot_id SET NOT NULL; +ALTER TABLE standard_buildroot ALTER COLUMN host_id SET NOT NULL; +ALTER TABLE standard_buildroot ALTER COLUMN repo_id SET NOT NULL; +ALTER TABLE standard_buildroot ALTER COLUMN task_id SET NOT NULL; +ALTER TABLE standard_buildroot ALTER COLUMN create_event SET NOT NULL; +ALTER TABLE standard_buildroot ALTER COLUMN create_event SET DEFAULT get_event(); +SELECT statement_timestamp(), 'Fixing up standard_buildroot table, foreign key constraints' as msg; +ALTER TABLE standard_buildroot ADD CONSTRAINT brfk FOREIGN KEY (buildroot_id) REFERENCES buildroot(id); +ALTER TABLE standard_buildroot ADD CONSTRAINT hfk FOREIGN KEY (host_id) REFERENCES host(id); +ALTER TABLE standard_buildroot ADD CONSTRAINT rfk FOREIGN KEY (repo_id) REFERENCES repo(id); +ALTER TABLE standard_buildroot ADD CONSTRAINT tfk FOREIGN KEY (task_id) REFERENCES task(id); +ALTER TABLE standard_buildroot ADD CONSTRAINT efk FOREIGN KEY (create_event) REFERENCES events(id) ; +SELECT statement_timestamp(), 'Fixing up standard_buildroot table, primary key' as msg; +ALTER TABLE standard_buildroot ADD PRIMARY KEY (buildroot_id); + + +SELECT statement_timestamp(), 'Altering buildroot table (dropping columns)' as msg; +ALTER TABLE buildroot DROP COLUMN host_id; +ALTER TABLE buildroot DROP COLUMN repo_id; +ALTER TABLE buildroot DROP COLUMN task_id; +ALTER TABLE buildroot DROP COLUMN create_event; +ALTER TABLE buildroot DROP COLUMN retire_event; +ALTER TABLE buildroot DROP COLUMN state; +ALTER TABLE buildroot DROP COLUMN dirtyness; + +SELECT statement_timestamp(), 'Altering buildroot table (adding columns)' as msg; +ALTER TABLE buildroot ADD COLUMN br_type INTEGER NOT NULL DEFAULT 0; +ALTER TABLE buildroot ADD COLUMN cg_id INTEGER REFERENCES content_generator (id); +ALTER TABLE buildroot ADD COLUMN cg_version TEXT; +ALTER TABLE buildroot ADD COLUMN container_type TEXT; +ALTER TABLE buildroot ADD COLUMN host_os TEXT; +ALTER TABLE buildroot ADD COLUMN host_arch TEXT; +ALTER TABLE buildroot ADD COLUMN extra TEXT; + +SELECT statement_timestamp(), 'Altering buildroot table (altering columns)' as msg; +ALTER TABLE buildroot RENAME arch TO container_arch; +ALTER TABLE buildroot ALTER COLUMN container_arch TYPE TEXT; +ALTER TABLE buildroot ALTER COLUMN br_type DROP DEFAULT; + +COMMIT; + diff --git a/schemas/schema-update-cgen2.sql b/schemas/schema-update-cgen2.sql new file mode 100644 index 0000000..2748567 --- /dev/null +++ b/schemas/schema-update-cgen2.sql @@ -0,0 +1,91 @@ +-- PLEASE READ +-- This was an interim schema update script for changes introduced after +-- 1.10.1. +-- You probably want schema-upgrade-1.10-1.11.sql instead of this + + +BEGIN; + +-- New tables + +SELECT statement_timestamp(), 'Creating new tables' as msg; + +CREATE TABLE btype ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +) WITHOUT OIDS; + +CREATE TABLE build_types ( + build_id INTEGER NOT NULL REFERENCES build(id), + btype_id INTEGER NOT NULL REFERENCES btype(id), + PRIMARY KEY (build_id, btype_id) +) WITHOUT OIDS; + +-- predefined build types + +SELECT statement_timestamp(), 'Adding predefined build types' as msg; +INSERT INTO btype(name) VALUES ('rpm'); +INSERT INTO btype(name) VALUES ('maven'); +INSERT INTO btype(name) VALUES ('win'); +INSERT INTO btype(name) VALUES ('image'); + +-- new column for archiveinfo + +SELECT statement_timestamp(), 'Altering archiveinfo table' as msg; +ALTER TABLE archiveinfo ADD COLUMN btype_id INTEGER REFERENCES btype(id); + +-- fill in legacy types +SELECT statement_timestamp(), 'Adding legacy btypes to builds' as msg; +INSERT INTO build_types(btype_id, build_id) + SELECT btype.id, maven_builds.build_id FROM btype JOIN maven_builds ON btype.name='maven'; +INSERT INTO build_types(btype_id, build_id) + SELECT btype.id, win_builds.build_id FROM btype JOIN win_builds ON btype.name='win'; +INSERT INTO build_types(btype_id, build_id) + SELECT btype.id, image_builds.build_id FROM btype JOIN image_builds ON btype.name='image'; +-- not sure if this is the best way to select rpm builds... +INSERT INTO build_types(btype_id, build_id) + SELECT DISTINCT btype.id, build_id FROM btype JOIN rpminfo ON btype.name='rpm' + WHERE build_id IS NOT NULL; + +SELECT statement_timestamp(), 'Adding legacy btypes to archiveinfo' as msg; +UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='maven' LIMIT 1) + WHERE (SELECT archive_id FROM maven_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; +UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='win' LIMIT 1) + WHERE (SELECT archive_id FROM win_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; +UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='image' LIMIT 1) + WHERE (SELECT archive_id FROM image_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; + +-- new component tables +SELECT statement_timestamp(), 'Creating new component tables' as msg; +CREATE TABLE archive_rpm_components AS SELECT image_id, rpm_id from image_listing; +CREATE TABLE archive_components AS SELECT image_id, archive_id from image_archive_listing; +-- doing it this way and fixing up after is *much* faster than creating the empty table +-- and using insert..select to populate + +SELECT statement_timestamp(), 'Fixing up component tables, rename columns' as msg; +ALTER TABLE archive_rpm_components RENAME image_id TO archive_id; +ALTER TABLE archive_components RENAME archive_id TO component_id; +ALTER TABLE archive_components RENAME image_id TO archive_id; +ALTER TABLE archive_rpm_components ALTER COLUMN rpm_id SET NOT NULL; +ALTER TABLE archive_rpm_components ALTER COLUMN archive_id SET NOT NULL; +ALTER TABLE archive_components ALTER COLUMN component_id SET NOT NULL; +ALTER TABLE archive_components ALTER COLUMN archive_id SET NOT NULL; + +SELECT statement_timestamp(), 'Fixing up component tables, adding constraints' as msg; +ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_archive_id_fkey FOREIGN KEY (archive_id) REFERENCES archiveinfo(id); +ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_rpm_id_fkey FOREIGN KEY (rpm_id) REFERENCES rpminfo(id); +ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_archive_id_rpm_id_key UNIQUE (archive_id, rpm_id); +ALTER TABLE archive_components ADD CONSTRAINT archive_components_archive_id_fkey FOREIGN KEY (archive_id) REFERENCES archiveinfo(id); +ALTER TABLE archive_components ADD CONSTRAINT archive_components_component_id_fkey FOREIGN KEY (component_id) REFERENCES archiveinfo(id); +ALTER TABLE archive_components ADD CONSTRAINT archive_components_archive_id_component_id_key UNIQUE (archive_id, component_id); + +SELECT statement_timestamp(), 'Adding component table indexes' as msg; +CREATE INDEX rpm_components_idx on archive_rpm_components(rpm_id); +CREATE INDEX archive_components_idx on archive_components(component_id); + + +-- image_listing and image_archive_listing are no longer used + + +COMMIT; + diff --git a/schemas/schema-update-dist-repos.sql b/schemas/schema-update-dist-repos.sql new file mode 100644 index 0000000..ef71423 --- /dev/null +++ b/schemas/schema-update-dist-repos.sql @@ -0,0 +1,7 @@ +# schema updates for dist repo feature +# to be merged into schema upgrade script for next release + +INSERT INTO permissions (name) VALUES ('image'); + +ALTER TABLE repo ADD COLUMN dist BOOLEAN DEFAULT 'false'; + diff --git a/schemas/schema-upgrade-1.10-1.11.sql b/schemas/schema-upgrade-1.10-1.11.sql new file mode 100644 index 0000000..4ae2bf5 --- /dev/null +++ b/schemas/schema-upgrade-1.10-1.11.sql @@ -0,0 +1,206 @@ + +BEGIN; + +-- from schema-update-cgen.sql + + +-- New tables + +SELECT statement_timestamp(), 'Creating new tables' as msg; + +CREATE TABLE content_generator ( + id SERIAL PRIMARY KEY, + name TEXT +) WITHOUT OIDS; + +CREATE TABLE cg_users ( + cg_id INTEGER NOT NULL REFERENCES content_generator (id), + user_id INTEGER NOT NULL REFERENCES users (id), +-- versioned + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, cg_id, user_id), + UNIQUE (cg_id, user_id, active) +) WITHOUT OIDS; + + +CREATE TABLE buildroot_tools_info ( + buildroot_id INTEGER NOT NULL REFERENCES buildroot(id), + tool TEXT NOT NULL, + version TEXT NOT NULL, + PRIMARY KEY (buildroot_id, tool) +) WITHOUT OIDS; + + +CREATE TABLE image_archive_listing ( + image_id INTEGER NOT NULL REFERENCES image_archives(archive_id), + archive_id INTEGER NOT NULL REFERENCES archiveinfo(id), + UNIQUE (image_id, archive_id) +) WITHOUT OIDS; +CREATE INDEX image_listing_archives on image_archive_listing(archive_id); + + +-- new columns -- + +select statement_timestamp(), 'Adding new columns' as msg; +ALTER TABLE build ADD COLUMN start_time TIMESTAMP; +ALTER TABLE build ADD COLUMN source TEXT; +ALTER TABLE build ADD COLUMN extra TEXT; +ALTER TABLE rpminfo ADD COLUMN metadata_only BOOLEAN NOT NULL DEFAULT FALSE; +ALTER TABLE rpminfo ADD COLUMN extra TEXT; +ALTER TABLE archiveinfo ADD COLUMN metadata_only BOOLEAN NOT NULL DEFAULT FALSE; +ALTER TABLE archiveinfo ADD COLUMN extra TEXT; + + +-- the more complicated stuff + +SELECT statement_timestamp(), 'Copying buildroot to standard_buildroot' as msg; +CREATE TABLE standard_buildroot AS SELECT id,host_id,repo_id,task_id,create_event,retire_event,state from buildroot; +-- doing it this way and fixing up after is *much* faster than creating the empty table +-- and using insert..select to populate + +SELECT statement_timestamp(), 'Fixing up standard_buildroot table' as msg; +ALTER TABLE standard_buildroot RENAME id TO buildroot_id; +ALTER TABLE standard_buildroot ALTER COLUMN buildroot_id SET NOT NULL; +ALTER TABLE standard_buildroot ALTER COLUMN host_id SET NOT NULL; +ALTER TABLE standard_buildroot ALTER COLUMN repo_id SET NOT NULL; +ALTER TABLE standard_buildroot ALTER COLUMN task_id SET NOT NULL; +ALTER TABLE standard_buildroot ALTER COLUMN create_event SET NOT NULL; +ALTER TABLE standard_buildroot ALTER COLUMN create_event SET DEFAULT get_event(); +SELECT statement_timestamp(), 'Fixing up standard_buildroot table, foreign key constraints' as msg; +ALTER TABLE standard_buildroot ADD CONSTRAINT standard_buildroot_buildroot_id_fkey FOREIGN KEY (buildroot_id) REFERENCES buildroot(id); +ALTER TABLE standard_buildroot ADD CONSTRAINT standard_buildroot_host_id_fkey FOREIGN KEY (host_id) REFERENCES host(id); +ALTER TABLE standard_buildroot ADD CONSTRAINT standard_buildroot_repo_id_fkey FOREIGN KEY (repo_id) REFERENCES repo(id); +ALTER TABLE standard_buildroot ADD CONSTRAINT standard_buildroot_task_id_fkey FOREIGN KEY (task_id) REFERENCES task(id); +ALTER TABLE standard_buildroot ADD CONSTRAINT standard_buildroot_create_event_fkey FOREIGN KEY (create_event) REFERENCES events(id) ; +SELECT statement_timestamp(), 'Fixing up standard_buildroot table, primary key' as msg; +ALTER TABLE standard_buildroot ADD PRIMARY KEY (buildroot_id); + + +SELECT statement_timestamp(), 'Altering buildroot table (dropping columns)' as msg; +ALTER TABLE buildroot DROP COLUMN host_id; +ALTER TABLE buildroot DROP COLUMN repo_id; +ALTER TABLE buildroot DROP COLUMN task_id; +ALTER TABLE buildroot DROP COLUMN create_event; +ALTER TABLE buildroot DROP COLUMN retire_event; +ALTER TABLE buildroot DROP COLUMN state; +ALTER TABLE buildroot DROP COLUMN dirtyness; + +SELECT statement_timestamp(), 'Altering buildroot table (adding columns)' as msg; +ALTER TABLE buildroot ADD COLUMN br_type INTEGER NOT NULL DEFAULT 0; +ALTER TABLE buildroot ADD COLUMN cg_id INTEGER REFERENCES content_generator (id); +ALTER TABLE buildroot ADD COLUMN cg_version TEXT; +ALTER TABLE buildroot ADD COLUMN container_type TEXT; +ALTER TABLE buildroot ADD COLUMN host_os TEXT; +ALTER TABLE buildroot ADD COLUMN host_arch TEXT; +ALTER TABLE buildroot ADD COLUMN extra TEXT; + +SELECT statement_timestamp(), 'Altering buildroot table (altering columns)' as msg; +ALTER TABLE buildroot RENAME arch TO container_arch; +ALTER TABLE buildroot ALTER COLUMN container_arch TYPE TEXT; +ALTER TABLE buildroot ALTER COLUMN br_type DROP DEFAULT; + +SELECT statement_timestamp(), 'Altering buildroot table (altering constraints)' as msg; +ALTER TABLE buildroot ADD CONSTRAINT cg_sane CHECK ( + (cg_id IS NULL AND cg_version IS NULL) + OR (cg_id IS NOT NULL AND cg_version IS NOT NULL)); +UPDATE buildroot SET container_type = 'chroot' WHERE container_type IS NULL AND container_arch IS NOT NULL; +ALTER TABLE buildroot ADD CONSTRAINT container_sane CHECK ( + (container_type IS NULL AND container_arch IS NULL) + OR (container_type IS NOT NULL AND container_arch IS NOT NULL)); +ALTER TABLE buildroot ALTER COLUMN container_arch DROP NOT NULL; + + + +-- from schema-update-cgen2.sql + + +-- New tables + +SELECT statement_timestamp(), 'Creating new tables' as msg; + +CREATE TABLE btype ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +) WITHOUT OIDS; + +CREATE TABLE build_types ( + build_id INTEGER NOT NULL REFERENCES build(id), + btype_id INTEGER NOT NULL REFERENCES btype(id), + PRIMARY KEY (build_id, btype_id) +) WITHOUT OIDS; + +-- predefined build types + +SELECT statement_timestamp(), 'Adding predefined build types' as msg; +INSERT INTO btype(name) VALUES ('rpm'); +INSERT INTO btype(name) VALUES ('maven'); +INSERT INTO btype(name) VALUES ('win'); +INSERT INTO btype(name) VALUES ('image'); + +-- new column for archiveinfo + +SELECT statement_timestamp(), 'Altering archiveinfo table' as msg; +ALTER TABLE archiveinfo ADD COLUMN btype_id INTEGER REFERENCES btype(id); + +-- fill in legacy types +SELECT statement_timestamp(), 'Adding legacy btypes to builds' as msg; +INSERT INTO build_types(btype_id, build_id) + SELECT btype.id, maven_builds.build_id FROM btype JOIN maven_builds ON btype.name='maven'; +INSERT INTO build_types(btype_id, build_id) + SELECT btype.id, win_builds.build_id FROM btype JOIN win_builds ON btype.name='win'; +INSERT INTO build_types(btype_id, build_id) + SELECT btype.id, image_builds.build_id FROM btype JOIN image_builds ON btype.name='image'; +-- not sure if this is the best way to select rpm builds... +INSERT INTO build_types(btype_id, build_id) + SELECT DISTINCT btype.id, build_id FROM btype JOIN rpminfo ON btype.name='rpm' + WHERE build_id IS NOT NULL; + +SELECT statement_timestamp(), 'Adding legacy btypes to archiveinfo' as msg; +UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='maven' LIMIT 1) + WHERE (SELECT archive_id FROM maven_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; +UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='win' LIMIT 1) + WHERE (SELECT archive_id FROM win_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; +UPDATE archiveinfo SET btype_id=(SELECT id FROM btype WHERE name='image' LIMIT 1) + WHERE (SELECT archive_id FROM image_archives WHERE archive_id=archiveinfo.id) IS NOT NULL; + +-- new component tables +SELECT statement_timestamp(), 'Creating new component tables' as msg; +CREATE TABLE archive_rpm_components AS SELECT image_id, rpm_id from image_listing; +CREATE TABLE archive_components AS SELECT image_id, archive_id from image_archive_listing; +-- doing it this way and fixing up after is *much* faster than creating the empty table +-- and using insert..select to populate + +SELECT statement_timestamp(), 'Fixing up component tables, rename columns' as msg; +ALTER TABLE archive_rpm_components RENAME image_id TO archive_id; +ALTER TABLE archive_components RENAME archive_id TO component_id; +ALTER TABLE archive_components RENAME image_id TO archive_id; +ALTER TABLE archive_rpm_components ALTER COLUMN rpm_id SET NOT NULL; +ALTER TABLE archive_rpm_components ALTER COLUMN archive_id SET NOT NULL; +ALTER TABLE archive_components ALTER COLUMN component_id SET NOT NULL; +ALTER TABLE archive_components ALTER COLUMN archive_id SET NOT NULL; + +SELECT statement_timestamp(), 'Fixing up component tables, adding constraints' as msg; +ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_archive_id_fkey FOREIGN KEY (archive_id) REFERENCES archiveinfo(id); +ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_rpm_id_fkey FOREIGN KEY (rpm_id) REFERENCES rpminfo(id); +ALTER TABLE archive_rpm_components ADD CONSTRAINT archive_rpm_components_archive_id_rpm_id_key UNIQUE (archive_id, rpm_id); +ALTER TABLE archive_components ADD CONSTRAINT archive_components_archive_id_fkey FOREIGN KEY (archive_id) REFERENCES archiveinfo(id); +ALTER TABLE archive_components ADD CONSTRAINT archive_components_component_id_fkey FOREIGN KEY (component_id) REFERENCES archiveinfo(id); +ALTER TABLE archive_components ADD CONSTRAINT archive_components_archive_id_component_id_key UNIQUE (archive_id, component_id); + +SELECT statement_timestamp(), 'Adding component table indexes' as msg; +CREATE INDEX rpm_components_idx on archive_rpm_components(rpm_id); +CREATE INDEX archive_components_idx on archive_components(component_id); + + +-- image_listing and image_archive_listing are no longer used + + +COMMIT; + diff --git a/schemas/schema-upgrade-1.11-1.12.sql b/schemas/schema-upgrade-1.11-1.12.sql new file mode 100644 index 0000000..8659de7 --- /dev/null +++ b/schemas/schema-upgrade-1.11-1.12.sql @@ -0,0 +1,11 @@ +BEGIN; + +-- from schema-update-dist-repos.sql + +INSERT INTO permissions (name) VALUES ('image'); + +ALTER TABLE repo ADD COLUMN dist BOOLEAN; +ALTER TABLE repo ALTER COLUMN dist SET DEFAULT 'false'; +UPDATE repo SET dist = 'false'; + +COMMIT; diff --git a/schemas/schema-upgrade-1.12-1.13.sql b/schemas/schema-upgrade-1.12-1.13.sql new file mode 100644 index 0000000..5a87ec3 --- /dev/null +++ b/schemas/schema-upgrade-1.12-1.13.sql @@ -0,0 +1,9 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.12 to 1.13 + +BEGIN; + +-- Change VARCHAR field for tag names to TEXT to allow longer tag names +ALTER TABLE tag ALTER COLUMN name TYPE TEXT; + +COMMIT; diff --git a/schemas/schema-upgrade-1.13-1.14.sql b/schemas/schema-upgrade-1.13-1.14.sql new file mode 100644 index 0000000..16b4227 --- /dev/null +++ b/schemas/schema-upgrade-1.13-1.14.sql @@ -0,0 +1,13 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.13 to 1.14 + +BEGIN; + +-- drop unused log_messages table +DROP TABLE log_messages; + +-- add yaml and xjb file type in archivetypes +insert into archivetypes (name, description, extensions) values ('yaml', 'YAML Ain''t Markup Language', 'yaml yml'); +insert into archivetypes (name, description, extensions) values ('xjb', 'JAXB(Java Architecture for XML Binding) Binding Customization File', 'xjb'); + +COMMIT; diff --git a/schemas/schema-upgrade-1.14-1.15.sql b/schemas/schema-upgrade-1.14-1.15.sql new file mode 100644 index 0000000..dd4e026 --- /dev/null +++ b/schemas/schema-upgrade-1.14-1.15.sql @@ -0,0 +1,3 @@ +-- Nothing to do +-- +-- There were no schema changes between 1.14 and 1.15 diff --git a/schemas/schema-upgrade-1.15-1.16.sql b/schemas/schema-upgrade-1.15-1.16.sql new file mode 100644 index 0000000..97586ba --- /dev/null +++ b/schemas/schema-upgrade-1.15-1.16.sql @@ -0,0 +1,66 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.14 to 1.16 + + +BEGIN; + +-- create host_config table +SELECT 'Creating table host_config'; +CREATE TABLE host_config ( + host_id INTEGER NOT NULL REFERENCES host(id), + arches TEXT, + capacity FLOAT CHECK (capacity > 1) NOT NULL DEFAULT 2.0, + description TEXT, + comment TEXT, + enabled BOOLEAN NOT NULL DEFAULT 'true', +-- versioned - see desc above + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, host_id), + UNIQUE (host_id, active) +) WITHOUT OIDS; +CREATE INDEX host_config_by_active_and_enabled ON host_config(active, enabled); + +-- copy starting data +-- CREATE FUNCTION pg_temp.user() returns INTEGER as $$ select id from users where name='nobody' $$ language SQL; +CREATE FUNCTION pg_temp.user() returns INTEGER as $$ select 1 $$ language SQL; +-- If you would like to use an existing user instead, then: +-- 1. edit the temporary function to look for the alternate user name + +SELECT 'Copying data from host to host_config'; +INSERT INTO host_config (host_id, arches, capacity, description, comment, enabled, creator_id) + SELECT id, arches, capacity, description, comment, enabled, pg_temp.user() FROM host; + +-- alter original table +SELECT 'Dropping moved columns'; +ALTER TABLE host DROP COLUMN arches; +ALTER TABLE host DROP COLUMN capacity; +ALTER TABLE host DROP COLUMN description; +ALTER TABLE host DROP COLUMN comment; +ALTER TABLE host DROP COLUMN enabled; + +-- history for host_channels +SELECT 'Adding versions to host_channels'; +ALTER TABLE host_channels ADD COLUMN create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(); +ALTER TABLE host_channels ADD COLUMN revoke_event INTEGER REFERENCES events(id); +-- we need some default for alter table, but drop it after +ALTER TABLE host_channels ADD COLUMN creator_id INTEGER NOT NULL REFERENCES users(id) DEFAULT pg_temp.user(); +ALTER TABLE host_channels ALTER COLUMN creator_id DROP DEFAULT; +ALTER TABLE host_channels ADD COLUMN revoker_id INTEGER REFERENCES users(id); +ALTER TABLE host_channels ADD COLUMN active BOOLEAN DEFAULT 'true' CHECK (active); +ALTER TABLE host_channels ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); +ALTER TABLE host_channels ADD PRIMARY KEY (create_event, host_id, channel_id); +ALTER TABLE host_channels ADD UNIQUE (host_id, channel_id, active); +ALTER TABLE host_channels DROP CONSTRAINT host_channels_host_id_channel_id_key; +-- drop potential very old constraint (https://pagure.io/koji/issue/1789) +ALTER TABLE host_channels DROP CONSTRAINT IF EXISTS host_channels_host_id_key; + +COMMIT; diff --git a/schemas/schema-upgrade-1.16-1.17.sql b/schemas/schema-upgrade-1.16-1.17.sql new file mode 100644 index 0000000..6cb9ad6 --- /dev/null +++ b/schemas/schema-upgrade-1.16-1.17.sql @@ -0,0 +1,13 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.16 to 1.17 + + +BEGIN; + +-- Change VARCHAR field for build_target names to TEXT to allow longer names +ALTER TABLE build_target ALTER COLUMN name TYPE TEXT; + +-- Allow different merge modes for mergerepo +ALTER TABLE tag_external_repos ADD COLUMN merge_mode TEXT DEFAULT 'koji'; + +COMMIT; diff --git a/schemas/schema-upgrade-1.17-1.18.sql b/schemas/schema-upgrade-1.17-1.18.sql new file mode 100644 index 0000000..751d7d7 --- /dev/null +++ b/schemas/schema-upgrade-1.17-1.18.sql @@ -0,0 +1,45 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.17 to 1.18 + + +BEGIN; + +-- new table for notifications' optouts +CREATE TABLE build_notifications_block ( + id SERIAL NOT NULL PRIMARY KEY, + user_id INTEGER NOT NULL REFERENCES users (id), + package_id INTEGER REFERENCES package (id), + tag_id INTEGER REFERENCES tag (id) +) WITHOUT OIDS; + +-- add tgz to list of tar's extensions +UPDATE archivetypes SET extensions = 'tar tar.gz tar.bz2 tar.xz tgz' WHERE name = 'tar'; +INSERT INTO archivetypes (name, description, extensions) VALUES ('vhdx', 'Hyper-V Virtual Hard Disk v2 image', 'vhdx'); + +-- add compressed raw-gzip and compressed qcow2 images +insert into archivetypes (name, description, extensions) values ('raw-gz', 'GZIP compressed raw disk image', 'raw.gz'); +insert into archivetypes (name, description, extensions) values ('qcow2-compressed', 'Compressed QCOW2 image', 'qcow2.gz qcow2.xz'); + +-- add better index for sessions +CREATE INDEX sessions_expired ON sessions(expired); + +-- table for content generator build reservations +CREATE TABLE build_reservations ( + build_id INTEGER NOT NULL REFERENCES build(id), + token VARCHAR(64), + created TIMESTAMP NOT NULL, + PRIMARY KEY (build_id) +) WITHOUT OIDS; +CREATE INDEX build_reservations_created ON build_reservations(created); + +ALTER TABLE build ADD COLUMN cg_id INTEGER REFERENCES content_generator(id); + + +-- new indexes added in 1.18 +CREATE INDEX tag_packages_active_tag_id ON tag_packages(active, tag_id); +CREATE INDEX tag_packages_create_event ON tag_packages(create_event); +CREATE INDEX tag_packages_revoke_event ON tag_packages(revoke_event); +CREATE INDEX tag_packages_owner ON tag_packages(owner); + + +COMMIT; diff --git a/schemas/schema-upgrade-1.18-1.19.sql b/schemas/schema-upgrade-1.18-1.19.sql new file mode 100644 index 0000000..e071f2a --- /dev/null +++ b/schemas/schema-upgrade-1.18-1.19.sql @@ -0,0 +1,93 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.18 to 1.19 + + +BEGIN; + +CREATE TABLE tag_package_owners ( + package_id INTEGER NOT NULL REFERENCES package(id), + tag_id INTEGER NOT NULL REFERENCES tag (id), + owner INTEGER NOT NULL REFERENCES users(id), +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, package_id, tag_id), + UNIQUE (package_id,tag_id,active) +) WITHOUT OIDS; + +CREATE OR REPLACE FUNCTION convert_owners() RETURNS SETOF tag_packages AS +$BODY$ +DECLARE + r tag_packages%rowtype; + r2 tag_packages%rowtype; + last_owner int; +BEGIN + FOR r IN SELECT package_id, tag_id FROM tag_packages GROUP BY package_id, tag_id ORDER BY package_id, tag_id + LOOP + last_owner := 0; + FOR r2 IN SELECT * FROM tag_packages WHERE package_id = r.package_id AND tag_id = r.tag_id ORDER BY create_event + LOOP + -- always use first and last (active) row + IF last_owner = 0 OR r2.active IS TRUE THEN + last_owner := r2.owner; + RETURN NEXT r2; -- return current row of SELECT + ELSE + -- copy others only if owner changed + IF last_owner <> r2.owner THEN + RETURN NEXT r2; + last_owner := r2.owner; + END IF; + END IF; + END LOOP; + END LOOP; + RETURN; +END +$BODY$ +LANGUAGE plpgsql; + +INSERT INTO tag_package_owners (SELECT package_id, tag_id, owner, create_event, revoke_event, creator_id, revoker_id, active FROM convert_owners()); +DROP INDEX IF EXISTS tag_packages_owner; +ALTER TABLE tag_packages DROP COLUMN owner; +DROP FUNCTION convert_owners(); + +-- add compressed iso-compressed, vhd-compressed, vhdx-compressed, and vmdk-compressed +insert into archivetypes (name, description, extensions) values ('iso-compressed', 'Compressed iso image', 'iso.gz iso.xz'); +insert into archivetypes (name, description, extensions) values ('vhd-compressed', 'Compressed VHD image', 'vhd.gz vhd.xz'); +insert into archivetypes (name, description, extensions) values ('vhdx-compressed', 'Compressed VHDx image', 'vhd.gz vhd.xz'); +insert into archivetypes (name, description, extensions) values ('vmdk-compressed', 'Compressed VMDK image', 'vmdk.gz vmdk.xz'); + +-- add kernel-image and imitramfs +insert into archivetypes (name, description, extensions) values ('kernel-image', 'Kernel BZ2 Image', 'vmlinuz vmlinuz.gz vmlinuz.xz'); +insert into archivetypes (name, description, extensions) values ('initramfs', 'Compressed Initramfs Image', 'img'); + +-- schema update for https://pagure.io/koji/issue/1629 +CREATE TABLE user_krb_principals ( + user_id INTEGER NOT NULL REFERENCES users(id), + krb_principal VARCHAR(255) NOT NULL UNIQUE, + PRIMARY KEY (user_id, krb_principal) +) WITHOUT OIDS; + +INSERT INTO user_krb_principals ( SELECT id, krb_principal FROM users WHERE users.krb_principal IS NOT NULL); + +ALTER TABLE users DROP COLUMN krb_principal; + +-- Disallow duplicate content generator names +ALTER TABLE content_generator ADD UNIQUE (name); +ALTER TABLE content_generator ALTER COLUMN name SET NOT NULL; + + +-- add all basic permissions +INSERT INTO permissions (name) SELECT 'dist-repo' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'dist-repo'); +INSERT INTO permissions (name) SELECT 'host' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'host'); +INSERT INTO permissions (name) SELECT 'image-import' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'image-import'); +INSERT INTO permissions (name) SELECT 'sign' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'sign'); +INSERT INTO permissions (name) SELECT 'tag' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'tag'); +INSERT INTO permissions (name) SELECT 'target' WHERE NOT EXISTS (SELECT 1 FROM permissions WHERE name = 'target'); + +COMMIT; diff --git a/schemas/schema-upgrade-1.19-1.20.sql b/schemas/schema-upgrade-1.19-1.20.sql new file mode 100644 index 0000000..66dcebe --- /dev/null +++ b/schemas/schema-upgrade-1.19-1.20.sql @@ -0,0 +1,10 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.19 to 1.20 + + +BEGIN; + +-- drop potential very old constraint (https://pagure.io/koji/issue/1789) +ALTER TABLE host_channels DROP CONSTRAINT IF EXISTS host_channels_host_id_key; + +COMMIT; diff --git a/schemas/schema-upgrade-1.2-1.3.sql b/schemas/schema-upgrade-1.2-1.3.sql new file mode 100644 index 0000000..c970115 --- /dev/null +++ b/schemas/schema-upgrade-1.2-1.3.sql @@ -0,0 +1,62 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.2 to 1.3 + +BEGIN; + +-- external yum repos +create table external_repo ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +); +-- fake repo id for internal stuff (needed for unique index) +INSERT INTO external_repo (id, name) VALUES (0, 'INTERNAL'); + +create table external_repo_config ( + external_repo_id INTEGER NOT NULL REFERENCES external_repo(id), + url TEXT NOT NULL, +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL ) + OR (active IS NOT NULL AND revoke_event IS NULL )), + PRIMARY KEY (create_event, external_repo_id), + UNIQUE (external_repo_id, active) +) WITHOUT OIDS; + +create table tag_external_repos ( + tag_id INTEGER NOT NULL REFERENCES tag(id), + external_repo_id INTEGER NOT NULL REFERENCES external_repo(id), + priority INTEGER NOT NULL, +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL ) + OR (active IS NOT NULL AND revoke_event IS NULL )), + PRIMARY KEY (create_event, tag_id, priority), + UNIQUE (tag_id, priority, active), + UNIQUE (tag_id, external_repo_id, active) +); + +-- add the new column then set the existing packages to have the INTERNAL exteranl repo id +-- then add the not null constraint +-- then drop rpminfo_unique_nvra CONSTRAINT and add the new version +ALTER TABLE rpminfo ADD COLUMN external_repo_id INTEGER REFERENCES external_repo(id); +UPDATE rpminfo SET external_repo_id = 0; +ALTER TABLE rpminfo ALTER COLUMN external_repo_id SET NOT NULL; +ALTER TABLE rpminfo DROP CONSTRAINT rpminfo_unique_nvra; +ALTER TABLE rpminfo ADD CONSTRAINT rpminfo_unique_nvra UNIQUE (name,version,release,arch,external_repo_id); + +GRANT SELECT ON external_repo, external_repo_config, tag_external_repos TO PUBLIC; + +-- these tables are no longer included with newer koji +-- feel free to drop them +-- DROP TABLE rpmfiles; +-- DROP TABLE rpmdeps; +-- DROP TABLE changelogs; +-- DROP TABLE archivefiles; + +COMMIT; diff --git a/schemas/schema-upgrade-1.20-1.21.sql b/schemas/schema-upgrade-1.20-1.21.sql new file mode 100644 index 0000000..0cce0dd --- /dev/null +++ b/schemas/schema-upgrade-1.20-1.21.sql @@ -0,0 +1,20 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.20 to 1.21 + + +BEGIN; + +-- make better events +ALTER TABLE events ALTER COLUMN time SET NOT NULL; +ALTER TABLE events ALTER COLUMN time SET DEFAULT clock_timestamp(); + +CREATE OR REPLACE FUNCTION get_event() RETURNS INTEGER AS ' + INSERT INTO events (time) VALUES (clock_timestamp()); + SELECT currval(''events_id_seq'')::INTEGER; +' LANGUAGE SQL; + +-- merge_mode can not be null +UPDATE tag_external_repos SET merge_mode = 'koji' WHERE merge_mode is NULL; +ALTER TABLE tag_external_repos ALTER COLUMN merge_mode SET NOT NULL; + +COMMIT; diff --git a/schemas/schema-upgrade-1.21-1.22.sql b/schemas/schema-upgrade-1.21-1.22.sql new file mode 100644 index 0000000..b07b87e --- /dev/null +++ b/schemas/schema-upgrade-1.21-1.22.sql @@ -0,0 +1,35 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.20 to 1.21 + + +BEGIN; + +ALTER TABLE events ALTER COLUMN time TYPE TIMESTAMPTZ USING + timezone(current_setting('TIMEZONE'), time::timestamptz); +ALTER TABLE sessions ALTER COLUMN start_time TYPE TIMESTAMPTZ USING + timezone(current_setting('TIMEZONE'), start_time::timestamptz); +ALTER TABLE sessions ALTER COLUMN update_time TYPE TIMESTAMPTZ USING + timezone(current_setting('TIMEZONE'), update_time::timestamptz); +ALTER TABLE task ALTER COLUMN create_time TYPE TIMESTAMPTZ USING + timezone(current_setting('TIMEZONE'), create_time::timestamptz); +ALTER TABLE task ALTER COLUMN start_time TYPE TIMESTAMPTZ USING + timezone(current_setting('TIMEZONE'), start_time::timestamptz); +ALTER TABLE task ALTER COLUMN completion_time TYPE TIMESTAMPTZ USING + timezone(current_setting('TIMEZONE'), completion_time::timestamptz); +ALTER TABLE build ALTER COLUMN start_time TYPE TIMESTAMPTZ USING + timezone(current_setting('TIMEZONE'), start_time::timestamptz); +ALTER TABLE build ALTER COLUMN completion_time TYPE TIMESTAMPTZ USING + timezone(current_setting('TIMEZONE'), completion_time::timestamptz); +ALTER TABLE build_reservations ALTER COLUMN created TYPE TIMESTAMPTZ USING + timezone(current_setting('TIMEZONE'), created::timestamptz); + +-- input type has to be specified on PostgreSQL 9.x +DROP FUNCTION IF EXISTS get_event_time(INTEGER); +CREATE FUNCTION get_event_time(INTEGER) RETURNS TIMESTAMPTZ AS ' + SELECT time FROM events WHERE id=$1; +' LANGUAGE SQL; + +DROP INDEX IF EXISTS sessions_active_and_recent; +CREATE INDEX sessions_active_and_recent ON sessions(expired, master, update_time) WHERE (expired = FALSE AND master IS NULL); + +COMMIT; diff --git a/schemas/schema-upgrade-1.22-1.23.sql b/schemas/schema-upgrade-1.22-1.23.sql new file mode 100644 index 0000000..b79ac29 --- /dev/null +++ b/schemas/schema-upgrade-1.22-1.23.sql @@ -0,0 +1,21 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.22 to 1.23 + + +BEGIN; + +CREATE INDEX task_by_no_parent_state_method ON task(parent, state, method) WHERE parent IS NULL; + +ALTER TABLE tag_extra ALTER COLUMN value DROP NOT NULL; + +-- Message queue for the protonmsg plugin +CREATE TABLE proton_queue ( + id SERIAL PRIMARY KEY, + created_ts TIMESTAMPTZ DEFAULT NOW(), + address TEXT NOT NULL, + props JSON NOT NULL, + body JSON NOT NULL +) WITHOUT OIDS; + + +COMMIT; diff --git a/schemas/schema-upgrade-1.23-1.24.sql b/schemas/schema-upgrade-1.23-1.24.sql new file mode 100644 index 0000000..998849a --- /dev/null +++ b/schemas/schema-upgrade-1.23-1.24.sql @@ -0,0 +1,9 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.23 to 1.24 + + +BEGIN; + +ALTER TABLE tag_external_repos ADD COLUMN arches TEXT; + +COMMIT; diff --git a/schemas/schema-upgrade-1.24-1.25.sql b/schemas/schema-upgrade-1.24-1.25.sql new file mode 100644 index 0000000..0ddf6f2 --- /dev/null +++ b/schemas/schema-upgrade-1.24-1.25.sql @@ -0,0 +1,9 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.24 to 1.25 + + +BEGIN; + +ALTER TABLE repo ADD COLUMN task_id INTEGER NULL REFERENCES task(id); + +COMMIT; diff --git a/schemas/schema-upgrade-1.25-1.26.sql b/schemas/schema-upgrade-1.25-1.26.sql new file mode 100644 index 0000000..18cdf5f --- /dev/null +++ b/schemas/schema-upgrade-1.25-1.26.sql @@ -0,0 +1,11 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.25 to 1.26 + + +BEGIN; + +ALTER TABLE channels ADD COLUMN description TEXT; +ALTER TABLE channels ADD COLUMN enabled BOOLEAN NOT NULL DEFAULT 'true'; +ALTER TABLE channels ADD COLUMN comment TEXT; + +COMMIT; diff --git a/schemas/schema-upgrade-1.27-1.28.sql b/schemas/schema-upgrade-1.27-1.28.sql new file mode 100644 index 0000000..a686d8b --- /dev/null +++ b/schemas/schema-upgrade-1.27-1.28.sql @@ -0,0 +1,24 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.27 to 1.28 + + +BEGIN; + +ALTER TABLE permissions ADD COLUMN description TEXT; + +UPDATE permissions set description='Full administrator access. Perform all actions.' WHERE name = 'admin'; +UPDATE permissions set description='Create appliance builds - deprecated.' WHERE name = 'appliance'; +UPDATE permissions set description='Create a dist-repo.' WHERE name = 'dist-repo'; +UPDATE permissions set description='Add, remove, enable, disable hosts and channels.' WHERE name = 'host'; +UPDATE permissions set description='Start image tasks.' WHERE name = 'image'; +UPDATE permissions set description='Import image archives.' WHERE name = 'image-import'; +UPDATE permissions set description='Start livecd tasks.' WHERE name = 'livecd'; +UPDATE permissions set description='Import maven archives.' WHERE name = 'maven-import'; +UPDATE permissions set description='Manage repos: newRepo, repoExpire, repoDelete, repoProblem.' WHERE name = 'repo'; +UPDATE permissions set description='Import RPM signatures and write signed RPMs.' WHERE name = 'sign'; +UPDATE permissions set description='Manage packages in tags: add, block, remove, and clone tags.' WHERE name = 'tag'; +UPDATE permissions set description='Add, edit, and remove targets.' WHERE name = 'target'; +UPDATE permissions set description='The default hub policy rule for "vm" requires this permission to trigger Windows builds.' WHERE name = 'win-admin'; +UPDATE permissions set description='Import win archives.' WHERE name = 'win-import'; + +COMMIT; diff --git a/schemas/schema-upgrade-1.28-1.29.sql b/schemas/schema-upgrade-1.28-1.29.sql new file mode 100644 index 0000000..10fe8a1 --- /dev/null +++ b/schemas/schema-upgrade-1.28-1.29.sql @@ -0,0 +1,5 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.28 to 1.29 + + +-- This version introduced no changes in db schema diff --git a/schemas/schema-upgrade-1.29-1.30.sql b/schemas/schema-upgrade-1.29-1.30.sql new file mode 100644 index 0000000..4ab6bc0 --- /dev/null +++ b/schemas/schema-upgrade-1.29-1.30.sql @@ -0,0 +1,19 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.29 to 1.30 + + +BEGIN; + +ALTER TABLE archivetypes ADD COLUMN compression_type TEXT; + +UPDATE archivetypes set compression_type='zip' WHERE name = 'jar'; +UPDATE archivetypes set compression_type='zip' WHERE name = 'zip'; +UPDATE archivetypes set compression_type='tar' WHERE name = 'tar'; + +-- clean some unused old indices if they still exist +-- https://pagure.io/koji/issue/3160 +DROP INDEX IF EXISTS image_listing_archives; +DROP INDEX IF EXISTS image_listing_rpms; +DROP INDEX IF EXISTS imageinfo_listing_rpms; + +COMMIT; diff --git a/schemas/schema-upgrade-1.3-1.4.sql b/schemas/schema-upgrade-1.3-1.4.sql new file mode 100644 index 0000000..3754ba2 --- /dev/null +++ b/schemas/schema-upgrade-1.3-1.4.sql @@ -0,0 +1,267 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.3 to 1.4 + +BEGIN; + +-- First the simple stuff. A pair of new host fields. +ALTER TABLE host ADD COLUMN description TEXT; +ALTER TABLE host ADD COLUMN comment TEXT; +-- ...and a new field for tasks +ALTER TABLE task ADD COLUMN start_time TIMESTAMP; + + +-- new standard permissions and channels +INSERT INTO permissions (name) VALUES ('maven-import'); +INSERT INTO permissions (name) VALUES ('appliance'); + +INSERT INTO channels (name) VALUES ('maven'); +INSERT INTO channels (name) VALUES ('appliance'); + + +-- extensions for maven support +ALTER TABLE tag_config ADD COLUMN maven_support BOOLEAN NOT NULL DEFAULT FALSE; +ALTER TABLE tag_config ADD COLUMN maven_include_all BOOLEAN NOT NULL DEFAULT FALSE; + +CREATE TABLE maven_builds ( + build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id), + group_id TEXT NOT NULL, + artifact_id TEXT NOT NULL, + version TEXT NOT NULL +) WITHOUT OIDS; + +CREATE TABLE archivetypes ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT NOT NULL UNIQUE, + description TEXT NOT NULL, + extensions TEXT NOT NULL +) WITHOUT OIDS; + +insert into archivetypes (name, description, extensions) values ('jar', 'Jar file', 'jar war rar ear'); +insert into archivetypes (name, description, extensions) values ('zip', 'Zip archive', 'zip'); +insert into archivetypes (name, description, extensions) values ('pom', 'Maven Project Object Management file', 'pom'); +insert into archivetypes (name, description, extensions) values ('tar', 'Tar file', 'tar tar.gz tar.bz2'); +insert into archivetypes (name, description, extensions) values ('xml', 'XML file', 'xml'); + +CREATE TABLE archiveinfo ( + id SERIAL NOT NULL PRIMARY KEY, + type_id INTEGER NOT NULL REFERENCES archivetypes (id), + build_id INTEGER NOT NULL REFERENCES build (id), + buildroot_id INTEGER REFERENCES buildroot (id), + filename TEXT NOT NULL, + size INTEGER NOT NULL, + md5sum TEXT NOT NULL +) WITHOUT OIDS; +CREATE INDEX archiveinfo_build_idx ON archiveinfo (build_id); +CREATE INDEX archiveinfo_buildroot_idx on archiveinfo (buildroot_id); +CREATE INDEX archiveinfo_type_idx on archiveinfo (type_id); +CREATE INDEX archiveinfo_filename_idx on archiveinfo(filename); + +CREATE TABLE maven_archives ( + archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), + group_id TEXT NOT NULL, + artifact_id TEXT NOT NULL, + version TEXT NOT NULL +) WITHOUT OIDS; + +CREATE TABLE buildroot_archives ( + buildroot_id INTEGER NOT NULL REFERENCES buildroot (id), + archive_id INTEGER NOT NULL REFERENCES archiveinfo (id), + project_dep BOOLEAN NOT NULL, + PRIMARY KEY (buildroot_id, archive_id) +) WITHOUT OIDS; +CREATE INDEX buildroot_archives_archive_idx ON buildroot_archives (archive_id); + + + +-- The rest updates all the versioned tables to track who did what + +-- One issue with this is that we need to provide creator/revoker data +-- for existing rows. Our approach is to create a disabled user to use +-- for this named 'nobody'. The temporary function is merely a convenient +-- way to reference the user we create. +INSERT INTO users (name, status, usertype) VALUES ('nobody', 1, 0); +CREATE FUNCTION pg_temp.user() returns INTEGER as $$ select id from users where name='nobody' $$ language SQL; +-- If you would like to use an existing user instead, then: +-- 1. comment out the users insert +-- 2. edit the temporary function to look for the alternate user name + +SELECT 'Updating table user_perms'; + +ALTER TABLE user_perms ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE user_perms ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE user_perms SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE user_perms SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE user_perms ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE user_perms DROP CONSTRAINT active_revoke_sane; +ALTER TABLE user_perms ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table user_groups'; + +ALTER TABLE user_groups ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE user_groups ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE user_groups SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE user_groups SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE user_groups ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE user_groups DROP CONSTRAINT active_revoke_sane; +ALTER TABLE user_groups ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table tag_inheritance'; + +ALTER TABLE tag_inheritance ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE tag_inheritance ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE tag_inheritance SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE tag_inheritance SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE tag_inheritance ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE tag_inheritance DROP CONSTRAINT active_revoke_sane; +ALTER TABLE tag_inheritance ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table tag_config'; + +ALTER TABLE tag_config ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE tag_config ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE tag_config SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE tag_config SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE tag_config ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE tag_config DROP CONSTRAINT active_revoke_sane; +ALTER TABLE tag_config ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table build_target_config'; + +ALTER TABLE build_target_config ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE build_target_config ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE build_target_config SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE build_target_config SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE build_target_config ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE build_target_config DROP CONSTRAINT active_revoke_sane; +ALTER TABLE build_target_config ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table external_repo_config'; + +ALTER TABLE external_repo_config ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE external_repo_config ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE external_repo_config SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE external_repo_config SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE external_repo_config ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE external_repo_config DROP CONSTRAINT active_revoke_sane; +ALTER TABLE external_repo_config ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table tag_external_repos'; + +ALTER TABLE tag_external_repos ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE tag_external_repos ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE tag_external_repos SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE tag_external_repos SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE tag_external_repos ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE tag_external_repos DROP CONSTRAINT active_revoke_sane; +ALTER TABLE tag_external_repos ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table tag_listing'; + +ALTER TABLE tag_listing ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE tag_listing ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE tag_listing SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE tag_listing SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE tag_listing ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE tag_listing DROP CONSTRAINT active_revoke_sane; +ALTER TABLE tag_listing ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table tag_packages'; + +ALTER TABLE tag_packages ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE tag_packages ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE tag_packages SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE tag_packages SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE tag_packages ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE tag_packages DROP CONSTRAINT active_revoke_sane; +ALTER TABLE tag_packages ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table group_config'; + +ALTER TABLE group_config ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE group_config ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE group_config SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE group_config SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE group_config ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE group_config DROP CONSTRAINT active_revoke_sane; +ALTER TABLE group_config ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table group_req_listing'; + +ALTER TABLE group_req_listing ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE group_req_listing ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE group_req_listing SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE group_req_listing SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE group_req_listing ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE group_req_listing DROP CONSTRAINT active_revoke_sane; +ALTER TABLE group_req_listing ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + + +SELECT 'Updating table group_package_listing'; + +ALTER TABLE group_package_listing ADD COLUMN creator_id INTEGER REFERENCES users(id); +ALTER TABLE group_package_listing ADD COLUMN revoker_id INTEGER REFERENCES users(id); + +UPDATE group_package_listing SET creator_id=pg_temp.user() WHERE creator_id IS NULL; +UPDATE group_package_listing SET revoker_id=pg_temp.user() WHERE revoker_id IS NULL AND revoke_event IS NOT NULL; + +ALTER TABLE group_package_listing ALTER COLUMN creator_id SET NOT NULL; +ALTER TABLE group_package_listing DROP CONSTRAINT active_revoke_sane; +ALTER TABLE group_package_listing ADD CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)); + +COMMIT; diff --git a/schemas/schema-upgrade-1.30-1.31.sql b/schemas/schema-upgrade-1.30-1.31.sql new file mode 100644 index 0000000..eee9e74 --- /dev/null +++ b/schemas/schema-upgrade-1.30-1.31.sql @@ -0,0 +1,17 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.30 to 1.31 + +BEGIN; + -- index for default search method for rpms, PG11+ can benefit from new include method + DO $$ + DECLARE version integer; + BEGIN + SELECT current_setting('server_version_num')::integer INTO version; + IF version >= 110000 THEN + EXECUTE 'CREATE INDEX rpminfo_filename ON rpminfo((name || ''-'' || version || ''-'' || release || ''.'' || arch || ''.rpm'')) INCLUDE (id);'; + ELSE + EXECUTE 'CREATE INDEX rpminfo_filename ON rpminfo((name || ''-'' || version || ''-'' || release || ''.'' || arch || ''.rpm''));'; + END IF; + END + $$; +COMMIT; diff --git a/schemas/schema-upgrade-1.31-1.32.sql b/schemas/schema-upgrade-1.31-1.32.sql new file mode 100644 index 0000000..2cf0cb3 --- /dev/null +++ b/schemas/schema-upgrade-1.31-1.32.sql @@ -0,0 +1,23 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.31 to 1.32 + +BEGIN; + + -- fix duplicate extension in archivetypes + UPDATE archivetypes SET extensions = 'vhdx.gz vhdx.xz' WHERE name = 'vhdx-compressed'; + + -- for tag if session is closed or not + ALTER TABLE sessions ADD COLUMN closed BOOLEAN NOT NULL DEFAULT FALSE; + ALTER TABLE sessions ADD CONSTRAINT no_closed_exclusive CHECK (closed IS FALSE OR "exclusive" IS NULL); + ALTER TABLE sessions DROP CONSTRAINT exclusive_expired_sane; + + -- track checksum of rpms + CREATE TABLE rpm_checksum ( + rpm_id INTEGER NOT NULL REFERENCES rpminfo(id), + sigkey TEXT NOT NULL, + checksum TEXT NOT NULL UNIQUE, + checksum_type SMALLINT NOT NULL, + PRIMARY KEY (rpm_id, sigkey, checksum_type) + ) WITHOUT OIDS; + CREATE INDEX rpm_checksum_rpm_id ON rpm_checksum(rpm_id); +COMMIT; diff --git a/schemas/schema-upgrade-1.32-1.33.sql b/schemas/schema-upgrade-1.32-1.33.sql new file mode 100644 index 0000000..9efb8d7 --- /dev/null +++ b/schemas/schema-upgrade-1.32-1.33.sql @@ -0,0 +1,15 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.32 to 1.33 + +BEGIN; + ALTER TABLE sessions ADD COLUMN renew_time TIMESTAMPTZ; + INSERT INTO archivetypes (name, description, extensions) VALUES ('checksum', 'Checksum file', 'sha256') ON CONFLICT DO NOTHING; + INSERT INTO archivetypes (name, description, extensions) VALUES ('changes', 'Kiwi changes file', 'changes.xz changes') ON CONFLICT DO NOTHING; + INSERT INTO archivetypes (name, description, extensions) VALUES ('packages', 'Kiwi packages listing', 'packages') ON CONFLICT DO NOTHING; + INSERT INTO archivetypes (name, description, extensions) VALUES ('verified', 'Kiwi verified package list', 'verified') ON CONFLICT DO NOTHING; + ALTER TABLE host ADD COLUMN update_time TIMESTAMPTZ; + CREATE TABLE locks ( + name TEXT NOT NULL PRIMARY KEY + ) WITHOUT OIDS; + INSERT INTO locks(name) VALUES('protonmsg-plugin'); +COMMIT; diff --git a/schemas/schema-upgrade-1.4-1.5.sql b/schemas/schema-upgrade-1.4-1.5.sql new file mode 100644 index 0000000..ccc4432 --- /dev/null +++ b/schemas/schema-upgrade-1.4-1.5.sql @@ -0,0 +1,36 @@ +-- upgrade script to migrate the Koji database schema +-- from version 1.4 to 1.5 + +BEGIN; + +INSERT INTO permissions (name) VALUES ('win-import'); +INSERT INTO permissions (name) VALUES ('win-admin'); + +INSERT INTO channels (name) VALUES ('vm'); + +insert into archivetypes (name, description, extensions) values ('spec', 'RPM spec file', 'spec'); +insert into archivetypes (name, description, extensions) values ('exe', 'Windows executable', 'exe'); +insert into archivetypes (name, description, extensions) values ('dll', 'Windows dynamic link library', 'dll'); +insert into archivetypes (name, description, extensions) values ('lib', 'Windows import library', 'lib'); +insert into archivetypes (name, description, extensions) values ('sys', 'Windows device driver', 'sys'); +insert into archivetypes (name, description, extensions) values ('inf', 'Windows driver information file', 'inf'); +insert into archivetypes (name, description, extensions) values ('cat', 'Windows catalog file', 'cat'); +insert into archivetypes (name, description, extensions) values ('msi', 'Windows Installer package', 'msi'); +insert into archivetypes (name, description, extensions) values ('pdb', 'Windows debug information', 'pdb'); +insert into archivetypes (name, description, extensions) values ('oem', 'Windows driver oem file', 'oem'); + +-- flag to indicate that a build is a Windows build +CREATE TABLE win_builds ( + build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id), + platform TEXT NOT NULL +) WITHOUT OIDS; + +-- Extended information about files built in Windows VMs +CREATE TABLE win_archives ( + archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), + relpath TEXT NOT NULL, + platforms TEXT NOT NULL, + flags TEXT +) WITHOUT OIDS; + +COMMIT WORK; diff --git a/schemas/schema-upgrade-1.6-1.7.sql b/schemas/schema-upgrade-1.6-1.7.sql new file mode 100644 index 0000000..614eb74 --- /dev/null +++ b/schemas/schema-upgrade-1.6-1.7.sql @@ -0,0 +1,25 @@ +BEGIN; + +CREATE TABLE volume ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +) WITHOUT OIDS; + +INSERT INTO volume (id, name) VALUES (0, 'DEFAULT'); + +ALTER TABLE build ADD COLUMN volume_id INTEGER REFERENCES volume (id); +UPDATE build SET volume_id = 0; +ALTER TABLE build ALTER COLUMN volume_id SET NOT NULL; + +CREATE TABLE tag_updates ( + id SERIAL NOT NULL PRIMARY KEY, + tag_id INTEGER NOT NULL REFERENCES tag(id), + update_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + updater_id INTEGER NOT NULL REFERENCES users(id), + update_type INTEGER NOT NULL +) WITHOUT OIDS; + +CREATE INDEX tag_updates_by_tag ON tag_updates (tag_id); +CREATE INDEX tag_updates_by_event ON tag_updates (update_event); + +COMMIT; diff --git a/schemas/schema-upgrade-1.7-1.8.sql b/schemas/schema-upgrade-1.7-1.8.sql new file mode 100644 index 0000000..60f5c19 --- /dev/null +++ b/schemas/schema-upgrade-1.7-1.8.sql @@ -0,0 +1,47 @@ +-- schema migration from version 1.7 to 1.8 +-- note: this update will require additional steps, please see the migration doc + +BEGIN; + + +-- The following tables are now obsolete: +-- imageinfo +-- imageinfo_listing +-- However, we cannot drop them until after we migrate the data + +-- create new image tables +CREATE TABLE image_builds ( + build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id) +) WITHOUT OIDS; + +CREATE TABLE image_archives ( + archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), + arch VARCHAR(16) NOT NULL +) WITHOUT OIDS; + +CREATE TABLE image_listing ( + image_id INTEGER NOT NULL REFERENCES image_archives(archive_id), + rpm_id INTEGER NOT NULL REFERENCES rpminfo(id), + UNIQUE (image_id, rpm_id) +) WITHOUT OIDS; +CREATE INDEX image_listing_rpms on image_listing(rpm_id); + +-- alter archiveinfo +ALTER TABLE archiveinfo ALTER COLUMN size TYPE BIGINT; +ALTER TABLE archiveinfo RENAME COLUMN md5sum TO checksum; +ALTER TABLE archiveinfo ADD COLUMN checksum_type INTEGER NOT NULL DEFAULT 0; +ALTER TABLE archiveinfo ALTER COLUMN checksum_type DROP DEFAULT; +-- the main schema has no default for checksum_type +-- this is just an easy way to populate the fields for the old entries + + + +-- new archive types +insert into archivetypes (name, description, extensions) values ('iso', 'CD/DVD Image', 'iso'); +insert into archivetypes (name, description, extensions) values ('raw', 'Raw disk image', 'raw'); +insert into archivetypes (name, description, extensions) values ('qcow', 'QCOW image', 'qcow'); +insert into archivetypes (name, description, extensions) values ('qcow2', 'QCOW2 image', 'qcow2'); +insert into archivetypes (name, description, extensions) values ('vmx', 'VMX image', 'vmx'); +insert into archivetypes (name, description, extensions) values ('xsd', 'XML Schema Definition', 'xsd'); + +COMMIT; diff --git a/schemas/schema-upgrade-1.8-1.9.sql b/schemas/schema-upgrade-1.8-1.9.sql new file mode 100644 index 0000000..00e39c7 --- /dev/null +++ b/schemas/schema-upgrade-1.8-1.9.sql @@ -0,0 +1,16 @@ + +BEGIN; + +-- new archive types +insert into archivetypes (name, description, extensions) values ('vmdk', 'vSphere image', 'vmdk'); +insert into archivetypes (name, description, extensions) values ('ova', 'OVA image', 'ova'); +insert into archivetypes (name, description, extensions) values ('ks', 'Kickstart', 'ks'); +insert into archivetypes (name, description, extensions) values ('cfg', 'Configuration file', 'cfg'); + +COMMIT; + +BEGIN; +-- it's harmless if this part fails. +-- there shouldn't be any references to this, but keep it in a separate transaction just in case +delete from archivetypes where name = 'vmx'; +COMMIT; diff --git a/schemas/schema-upgrade-1.9-1.10.sql b/schemas/schema-upgrade-1.9-1.10.sql new file mode 100644 index 0000000..b70698d --- /dev/null +++ b/schemas/schema-upgrade-1.9-1.10.sql @@ -0,0 +1,50 @@ + +BEGIN; + +INSERT INTO channels (name) VALUES ('image'); + + +CREATE TABLE tag_extra ( + tag_id INTEGER NOT NULL REFERENCES tag(id), + key TEXT NOT NULL, + value TEXT NOT NULL, -- TODO - move this to jsonb when we can +-- versioned - see desc above + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, tag_id, key), + UNIQUE (tag_id, key, active) +) WITHOUT OIDS; + + +update archivetypes set extensions='jar war rar ear sar jdocbook jdocbook-style' where name='jar'; +update archivetypes set description='Zip file' where name='zip'; +update archivetypes set extensions='tar tar.gz tar.bz2 tar.xz' where name='tar'; +update archivetypes set description='Open Virtualization Archive' where name='ova'; + +insert into archivetypes (name, description, extensions) values ('vdi', 'VirtualBox Virtual Disk Image', 'vdi'); +insert into archivetypes (name, description, extensions) values ('aar', 'Binary distribution of an Android Library project', 'aar'); +insert into archivetypes (name, description, extensions) values ('apklib', 'Source distribution of an Android Library project', 'apklib'); +insert into archivetypes (name, description, extensions) values ('cab', 'Windows cabinet file', 'cab'); +insert into archivetypes (name, description, extensions) values ('dylib', 'OS X dynamic library', 'dylib'); +insert into archivetypes (name, description, extensions) values ('gem', 'Ruby gem', 'gem'); +insert into archivetypes (name, description, extensions) values ('ini', 'INI config file', 'ini'); +insert into archivetypes (name, description, extensions) values ('js', 'Javascript file', 'js'); +insert into archivetypes (name, description, extensions) values ('ldif', 'LDAP Data Interchange Format file', 'ldif'); +insert into archivetypes (name, description, extensions) values ('manifest', 'Runtime environment for .NET applications', 'manifest'); +insert into archivetypes (name, description, extensions) values ('msm', 'Windows merge module', 'msm'); +insert into archivetypes (name, description, extensions) values ('properties', 'Properties file', 'properties'); +insert into archivetypes (name, description, extensions) values ('sig', 'Signature file', 'sig signature'); +insert into archivetypes (name, description, extensions) values ('so', 'Shared library', 'so'); +insert into archivetypes (name, description, extensions) values ('txt', 'Text file', 'txt'); +insert into archivetypes (name, description, extensions) values ('vhd', 'Hyper-V image', 'vhd'); +insert into archivetypes (name, description, extensions) values ('wsf', 'Windows script file', 'wsf'); +insert into archivetypes (name, description, extensions) values ('box', 'Vagrant Box Image', 'box'); +insert into archivetypes (name, description, extensions) values ('raw-xz', 'xz compressed raw disk image', 'raw.xz'); + +COMMIT; diff --git a/schemas/schema.sql b/schemas/schema.sql new file mode 100644 index 0000000..5fa6a22 --- /dev/null +++ b/schemas/schema.sql @@ -0,0 +1,992 @@ + +-- vim:et:sw=8 + +BEGIN WORK; + +-- We use the events table to sequence time +-- in the event that the system clock rolls back, event_ids will retain proper sequencing +CREATE TABLE events ( + id SERIAL NOT NULL PRIMARY KEY, + time TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp() +) WITHOUT OIDS; + +-- A function that creates an event and returns the id, used as DEFAULT value for versioned tables +CREATE FUNCTION get_event() RETURNS INTEGER AS ' + INSERT INTO events (time) VALUES (clock_timestamp()); + SELECT currval(''events_id_seq'')::INTEGER; +' LANGUAGE SQL; + +-- A convenience function for converting events to timestamps, useful for +-- quick queries where you want to avoid JOINs. +CREATE FUNCTION get_event_time(INTEGER) RETURNS TIMESTAMPTZ AS ' + SELECT time FROM events WHERE id=$1; +' LANGUAGE SQL; + +-- this table is used to label events +-- most events will be unlabeled, so keeping this separate saves space +CREATE TABLE event_labels ( + event_id INTEGER NOT NULL REFERENCES events(id), + label VARCHAR(255) UNIQUE NOT NULL +) WITHOUT OIDS; + + +-- User and session data +CREATE TABLE users ( + id SERIAL NOT NULL PRIMARY KEY, + name VARCHAR(255) UNIQUE NOT NULL, + password VARCHAR(255), + status INTEGER NOT NULL, + usertype INTEGER NOT NULL +) WITHOUT OIDS; + +CREATE TABLE user_krb_principals ( + user_id INTEGER NOT NULL REFERENCES users(id), + krb_principal VARCHAR(255) NOT NULL UNIQUE, + PRIMARY KEY (user_id, krb_principal) +) WITHOUT OIDS; + +CREATE TABLE permissions ( + id SERIAL NOT NULL PRIMARY KEY, + name VARCHAR(50) UNIQUE NOT NULL, + description TEXT +) WITHOUT OIDS; + +-- Some basic perms +INSERT INTO permissions (name, description) VALUES ('admin', 'Full administrator access. Perform all actions.'); +INSERT INTO permissions (name, description) VALUES ('appliance', 'Create appliance builds - deprecated.'); +INSERT INTO permissions (name, description) VALUES ('dist-repo', 'Create a dist-repo.'); +INSERT INTO permissions (name, description) VALUES ('host', 'Add, remove, enable, disable hosts and channels.'); +INSERT INTO permissions (name, description) VALUES ('image', 'Start image tasks.'); +INSERT INTO permissions (name, description) VALUES ('image-import', 'Import image archives.'); +INSERT INTO permissions (name, description) VALUES ('livecd', 'Start livecd tasks.'); +INSERT INTO permissions (name, description) VALUES ('maven-import', 'Import maven archives.'); +INSERT INTO permissions (name, description) VALUES ('repo', 'Manage repos: newRepo, repoExpire, repoDelete, repoProblem.'); +INSERT INTO permissions (name, description) VALUES ('sign', 'Import RPM signatures and write signed RPMs.'); +INSERT INTO permissions (name, description) VALUES ('tag', 'Manage packages in tags: add, block, remove, and clone tags.'); +INSERT INTO permissions (name, description) VALUES ('target', 'Add, edit, and remove targets.'); +INSERT INTO permissions (name, description) VALUES ('win-admin', 'The default hub policy rule for "vm" requires this permission to trigger Windows builds.'); +INSERT INTO permissions (name, description) VALUES ('win-import', 'Import win archives.'); + +CREATE TABLE user_perms ( + user_id INTEGER NOT NULL REFERENCES users(id), + perm_id INTEGER NOT NULL REFERENCES permissions(id), +-- versioned - see VERSIONING + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, user_id, perm_id), + UNIQUE (user_id,perm_id,active) +) WITHOUT OIDS; + +-- groups are represented as users w/ usertype=2 +CREATE TABLE user_groups ( + user_id INTEGER NOT NULL REFERENCES users(id), + group_id INTEGER NOT NULL REFERENCES users(id), +-- versioned - see VERSIONING + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, user_id, group_id), + UNIQUE (user_id,group_id,active) +) WITHOUT OIDS; + +-- a session can create subsessions, which are just new sessions whose +-- 'master' field points back to the session. This field should +-- always point to the top session. If the master session is expired, +-- the all its subsessions should be expired as well. +-- If a session is exclusive, it is the only session allowed for its +-- user. The 'exclusive' field is either NULL or TRUE, never FALSE. This +-- is so exclusivity can be enforced with a unique condition. +CREATE TABLE sessions ( + id SERIAL NOT NULL PRIMARY KEY, + user_id INTEGER NOT NULL REFERENCES users(id), + expired BOOLEAN NOT NULL DEFAULT FALSE, + master INTEGER REFERENCES sessions(id), + key VARCHAR(255), + authtype INTEGER, + hostip VARCHAR(255), + callnum INTEGER, + start_time TIMESTAMPTZ NOT NULL DEFAULT NOW(), + update_time TIMESTAMPTZ NOT NULL DEFAULT NOW(), + exclusive BOOLEAN CHECK (exclusive), + closed BOOLEAN NOT NULL DEFAULT FALSE, + renew_time TIMESTAMPTZ, + CONSTRAINT no_exclusive_subsessions CHECK ( + master IS NULL OR "exclusive" IS NULL), + CONSTRAINT no_closed_exclusive CHECK ( + closed IS FALSE OR "exclusive" IS NULL), + UNIQUE (user_id,exclusive) +) WITHOUT OIDS; +CREATE INDEX sessions_master ON sessions(master); +CREATE INDEX sessions_active_and_recent ON sessions(expired, master, update_time) WHERE (expired = FALSE AND master IS NULL); +CREATE INDEX sessions_expired ON sessions(expired); + +-- Channels are used to limit which tasks are run on which machines. +-- Each task is assigned to a channel and each host 'listens' on one +-- or more channels. A host will only accept tasks for channels it is +-- listening to. +CREATE TABLE channels ( + id SERIAL NOT NULL PRIMARY KEY, + name VARCHAR(128) UNIQUE NOT NULL, + description TEXT, + enabled BOOLEAN NOT NULL DEFAULT 'true', + comment TEXT +) WITHOUT OIDS; + +-- create default channel +INSERT INTO channels (name) VALUES ('default'); +INSERT INTO channels (name) VALUES ('createrepo'); +INSERT INTO channels (name) VALUES ('maven'); +INSERT INTO channels (name) VALUES ('livecd'); +INSERT INTO channels (name) VALUES ('appliance'); +INSERT INTO channels (name) VALUES ('vm'); +INSERT INTO channels (name) VALUES ('image'); +INSERT INTO channels (name) VALUES ('livemedia'); + +-- Here we track the build machines +-- each host has an entry in the users table also +-- capacity: the hosts weighted task capacity +CREATE TABLE host ( + id SERIAL NOT NULL PRIMARY KEY, + user_id INTEGER NOT NULL REFERENCES users (id), + name VARCHAR(128) UNIQUE NOT NULL, + update_time TIMESTAMPTZ, + task_load FLOAT CHECK (NOT task_load < 0) NOT NULL DEFAULT 0.0, + ready BOOLEAN NOT NULL DEFAULT 'false' +) WITHOUT OIDS; + +CREATE TABLE host_config ( + host_id INTEGER NOT NULL REFERENCES host(id), + arches TEXT, + capacity FLOAT CHECK (capacity > 1) NOT NULL DEFAULT 2.0, + description TEXT, + comment TEXT, + enabled BOOLEAN NOT NULL DEFAULT 'true', +-- versioned - see desc above + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, host_id), + UNIQUE (host_id, active) +) WITHOUT OIDS; +CREATE INDEX host_config_by_active_and_enabled ON host_config(active, enabled); + +CREATE TABLE host_channels ( + host_id INTEGER NOT NULL REFERENCES host(id), + channel_id INTEGER NOT NULL REFERENCES channels(id), +-- versioned - see desc above + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, host_id, channel_id), + UNIQUE (host_id, channel_id, active) +) WITHOUT OIDS; + + +-- tasks are pretty general and may refer to all sorts of jobs, not +-- just package builds. +-- tasks may spawn subtasks (hence the parent field) +-- top-level tasks have NULL parent +-- the request and result fields are xmlrpc data. +-- this means each task is effectively an xmlrpc call, using this table as +-- the medium. +-- the host_id field indicates which host is running the task. This field +-- is used to lock the task. +-- weight: the weight of the task (vs. host capacity) +-- label: this field is used to label subtasks. top-level tasks will not +-- have a label. some subtasks may be unlabeled. labels are used in task +-- failover to prevent duplication of work. +CREATE TABLE task ( + id SERIAL NOT NULL PRIMARY KEY, + state INTEGER, + create_time TIMESTAMPTZ NOT NULL DEFAULT NOW(), + start_time TIMESTAMPTZ, + completion_time TIMESTAMPTZ, + channel_id INTEGER NOT NULL REFERENCES channels(id), + host_id INTEGER REFERENCES host (id), + parent INTEGER REFERENCES task (id), + label VARCHAR(255), + waiting BOOLEAN, + awaited BOOLEAN, + owner INTEGER REFERENCES users(id) NOT NULL, + method TEXT, + request TEXT, + result TEXT, + eta INTEGER, + arch VARCHAR(16) NOT NULL, + priority INTEGER, + weight FLOAT CHECK (NOT weight < 0) NOT NULL DEFAULT 1.0, + CONSTRAINT parent_label_sane CHECK ( + parent IS NOT NULL OR label IS NULL), + UNIQUE (parent,label) +) WITHOUT OIDS; + +CREATE INDEX task_by_state ON task (state); +-- CREATE INDEX task_by_parent ON task (parent); (unique condition creates similar index) +CREATE INDEX task_by_host ON task (host_id); +CREATE INDEX task_by_no_parent_state_method ON task(parent, state, method) WHERE parent IS NULL; + + +-- by package, we mean srpm +-- we mean the package in general, not an individual build +CREATE TABLE package ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +) WITHOUT OIDS; + +-- CREATE INDEX package_by_name ON package (name); +-- (implicitly created by unique constraint) + + +CREATE TABLE volume ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +) WITHOUT OIDS; + +INSERT INTO volume (id, name) VALUES (0, 'DEFAULT'); + +-- data for content generators +CREATE TABLE content_generator ( + id SERIAL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +) WITHOUT OIDS; + +-- here we track the built packages +-- this is at the srpm level, since builds are by srpm +-- see rpminfo for isolated packages +-- even though we track epoch, we demand that N-V-R be unique +-- task_id: a reference to the task creating the build, may be +-- null, or may point to a deleted task. +CREATE TABLE build ( + id SERIAL NOT NULL PRIMARY KEY, + volume_id INTEGER NOT NULL REFERENCES volume (id), + pkg_id INTEGER NOT NULL REFERENCES package (id) DEFERRABLE, + version TEXT NOT NULL, + release TEXT NOT NULL, + epoch INTEGER, + source TEXT, + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + start_time TIMESTAMPTZ, + completion_time TIMESTAMPTZ, + state INTEGER NOT NULL, + task_id INTEGER REFERENCES task (id), + owner INTEGER NOT NULL REFERENCES users (id), + cg_id INTEGER REFERENCES content_generator(id), + extra TEXT, + CONSTRAINT build_pkg_ver_rel UNIQUE (pkg_id, version, release), + CONSTRAINT completion_sane CHECK ((state = 0 AND completion_time IS NULL) OR + (state != 0 AND completion_time IS NOT NULL)) +) WITHOUT OIDS; + +CREATE INDEX build_by_pkg_id ON build (pkg_id); +CREATE INDEX build_completion ON build(completion_time); + + +CREATE TABLE btype ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +) WITHOUT OIDS; + + +-- legacy build types +INSERT INTO btype(name) VALUES ('rpm'); +INSERT INTO btype(name) VALUES ('maven'); +INSERT INTO btype(name) VALUES ('win'); +INSERT INTO btype(name) VALUES ('image'); + + +CREATE TABLE build_types ( + build_id INTEGER NOT NULL REFERENCES build(id), + btype_id INTEGER NOT NULL REFERENCES btype(id), + PRIMARY KEY (build_id, btype_id) +) WITHOUT OIDS; + + +-- Note: some of these CREATEs may seem a little out of order. This is done to keep +-- the references sane. + +CREATE TABLE tag ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +) WITHOUT OIDS; + +-- CREATE INDEX tag_by_name ON tag (name); +-- (implicitly created by unique constraint) + + +-- VERSIONING +-- Several tables are versioned with the following scheme. Since this +-- is the first, here is the explanation of how it works. +-- The versioning fields are: create_event, revoke_event, and active +-- The active field is either True or NULL, it is never False! +-- The create_event and revoke_event fields refer to the event table +-- A version is active if active is not NULL +-- (an active version also has NULL revoke_event.) +-- A UNIQUE condition can incorporate the 'active' field, making it +-- apply only to the active versions. +-- When a version is made inactive (revoked): +-- revoke_event is set +-- active is set to NULL +-- Query for current data with WHERE active is not NULL +-- (should be same as WHERE revoke_event is NULL) +-- Query for data at event e with WHERE create_event <= e AND e < revoke_event +CREATE TABLE tag_inheritance ( + tag_id INTEGER NOT NULL REFERENCES tag(id), + parent_id INTEGER NOT NULL REFERENCES tag(id), + priority INTEGER NOT NULL, + maxdepth INTEGER, + intransitive BOOLEAN NOT NULL DEFAULT 'false', + noconfig BOOLEAN NOT NULL DEFAULT 'false', + pkg_filter TEXT, +-- versioned - see desc above + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, tag_id, priority), + UNIQUE (tag_id,priority,active), + UNIQUE (tag_id,parent_id,active) +) WITHOUT OIDS; + +CREATE INDEX tag_inheritance_by_parent ON tag_inheritance (parent_id); + +-- XXX - need more config options listed here +-- perm_id: the permission that is required to apply the tag. can be NULL +-- +CREATE TABLE tag_config ( + tag_id INTEGER NOT NULL REFERENCES tag(id), + arches TEXT, + perm_id INTEGER REFERENCES permissions(id), + locked BOOLEAN NOT NULL DEFAULT 'false', + maven_support BOOLEAN NOT NULL DEFAULT FALSE, + maven_include_all BOOLEAN NOT NULL DEFAULT FALSE, +-- versioned - see desc above + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, tag_id), + UNIQUE (tag_id,active) +) WITHOUT OIDS; + +CREATE TABLE tag_extra ( + tag_id INTEGER NOT NULL REFERENCES tag(id), + key TEXT NOT NULL, + value TEXT, +-- versioned - see desc above + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, tag_id, key), + UNIQUE (tag_id, key, active) +) WITHOUT OIDS; + +-- the tag_updates table provides a mechanism to indicate changes relevant to tag +-- that are not reflected in a versioned table. For example: builds changing volumes, +-- changes to external repo content, additional rpms imported to an existing build +CREATE TABLE tag_updates ( + id SERIAL NOT NULL PRIMARY KEY, + tag_id INTEGER NOT NULL REFERENCES tag(id), + update_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + updater_id INTEGER NOT NULL REFERENCES users(id), + update_type INTEGER NOT NULL +) WITHOUT OIDS; + +CREATE INDEX tag_updates_by_tag ON tag_updates (tag_id); +CREATE INDEX tag_updates_by_event ON tag_updates (update_event); + +-- a build target tells the system where to build the package +-- and how to tag it afterwards. +CREATE TABLE build_target ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +) WITHOUT OIDS; + + +CREATE TABLE build_target_config ( + build_target_id INTEGER NOT NULL REFERENCES build_target(id), + build_tag INTEGER NOT NULL REFERENCES tag(id), + dest_tag INTEGER NOT NULL REFERENCES tag(id), +-- versioned - see desc above + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, build_target_id), + UNIQUE (build_target_id,active) +) WITHOUT OIDS; + + +-- track repos +CREATE TABLE repo ( + id SERIAL NOT NULL PRIMARY KEY, + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + tag_id INTEGER NOT NULL REFERENCES tag(id), + state INTEGER, + dist BOOLEAN DEFAULT 'false', + task_id INTEGER NULL REFERENCES task(id) +) WITHOUT OIDS; + +-- external yum repos +create table external_repo ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT UNIQUE NOT NULL +); +-- fake repo id for internal stuff (needed for unique index) +INSERT INTO external_repo (id, name) VALUES (0, 'INTERNAL'); + +CREATE TABLE external_repo_config ( + external_repo_id INTEGER NOT NULL REFERENCES external_repo(id), + url TEXT NOT NULL, +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, external_repo_id), + UNIQUE (external_repo_id, active) +) WITHOUT OIDS; + +CREATE TABLE tag_external_repos ( + tag_id INTEGER NOT NULL REFERENCES tag(id), + external_repo_id INTEGER NOT NULL REFERENCES external_repo(id), + priority INTEGER NOT NULL, + merge_mode TEXT NOT NULL DEFAULT 'koji', + arches TEXT, +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, tag_id, priority), + UNIQUE (tag_id, priority, active), + UNIQUE (tag_id, external_repo_id, active) +); + +CREATE TABLE cg_users ( + cg_id INTEGER NOT NULL REFERENCES content_generator (id), + user_id INTEGER NOT NULL REFERENCES users (id), +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, cg_id, user_id), + UNIQUE (cg_id, user_id, active) +) WITHOUT OIDS; + +CREATE TABLE build_reservations ( + build_id INTEGER NOT NULL REFERENCES build(id), + token VARCHAR(64), + created TIMESTAMPTZ NOT NULL, + PRIMARY KEY (build_id) +) WITHOUT OIDS; +CREATE INDEX build_reservations_created ON build_reservations(created); + +-- here we track the buildroots on the machines +CREATE TABLE buildroot ( + id SERIAL NOT NULL PRIMARY KEY, + br_type INTEGER NOT NULL, + cg_id INTEGER REFERENCES content_generator (id), + cg_version TEXT, + CONSTRAINT cg_sane CHECK ( + (cg_id IS NULL AND cg_version IS NULL) + OR (cg_id IS NOT NULL AND cg_version IS NOT NULL)), + container_type TEXT, + container_arch TEXT, + CONSTRAINT container_sane CHECK ( + (container_type IS NULL AND container_arch IS NULL) + OR (container_type IS NOT NULL AND container_arch IS NOT NULL)), + host_os TEXT, + host_arch TEXT, + extra TEXT +) WITHOUT OIDS; + +CREATE TABLE standard_buildroot ( + buildroot_id INTEGER NOT NULL PRIMARY KEY REFERENCES buildroot(id), + host_id INTEGER NOT NULL REFERENCES host(id), + repo_id INTEGER NOT NULL REFERENCES repo (id), + task_id INTEGER NOT NULL REFERENCES task (id), + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + retire_event INTEGER, + state INTEGER +) WITHOUT OIDS; + +CREATE TABLE buildroot_tools_info ( + buildroot_id INTEGER NOT NULL REFERENCES buildroot(id), + tool TEXT NOT NULL, + version TEXT NOT NULL, + PRIMARY KEY (buildroot_id, tool) +) WITHOUT OIDS; + + +-- track spun images (livecds, installation, VMs...) +CREATE TABLE image_builds ( + build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id) +) WITHOUT OIDS; + +-- this table associates tags with builds. an entry here tags a package +CREATE TABLE tag_listing ( + build_id INTEGER NOT NULL REFERENCES build (id), + tag_id INTEGER NOT NULL REFERENCES tag (id), +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, build_id, tag_id), + UNIQUE (build_id,tag_id,active) +) WITHOUT OIDS; +CREATE INDEX tag_listing_tag_id_key ON tag_listing(tag_id); + +-- this is a per-tag list of packages, with some extra info +-- so this allows you to explicitly state which packages belong where +-- (as opposed to beehive where this can only be done at the collection level) +-- these are packages in general, not specific builds. +-- this list limits which builds can be tagged with which tags +-- if blocked is true, then the package is specifically not included. this +-- prevents the package from being included via inheritance +CREATE TABLE tag_packages ( + package_id INTEGER NOT NULL REFERENCES package (id), + tag_id INTEGER NOT NULL REFERENCES tag (id), + blocked BOOLEAN NOT NULL DEFAULT FALSE, + extra_arches TEXT, +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, package_id, tag_id), + UNIQUE (package_id,tag_id,active) +) WITHOUT OIDS; +CREATE INDEX tag_packages_active_tag_id ON tag_packages(active, tag_id); +CREATE INDEX tag_packages_create_event ON tag_packages(create_event); +CREATE INDEX tag_packages_revoke_event ON tag_packages(revoke_event); + +CREATE TABLE tag_package_owners ( + package_id INTEGER NOT NULL REFERENCES package(id), + tag_id INTEGER NOT NULL REFERENCES tag (id), + owner INTEGER NOT NULL REFERENCES users(id), +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, package_id, tag_id), + UNIQUE (package_id,tag_id,active) +) WITHOUT OIDS; + +-- package groups (per tag). used for generating comps for the tag repos +CREATE TABLE groups ( + id SERIAL NOT NULL PRIMARY KEY, + name VARCHAR(50) UNIQUE NOT NULL + -- corresponds to the id field in a comps group +) WITHOUT OIDS; + +-- if blocked is true, then the group is specifically not included. this +-- prevents the group from being included via inheritance +CREATE TABLE group_config ( + group_id INTEGER NOT NULL REFERENCES groups (id), + tag_id INTEGER NOT NULL REFERENCES tag (id), + blocked BOOLEAN NOT NULL DEFAULT FALSE, + exported BOOLEAN DEFAULT TRUE, + display_name TEXT NOT NULL, + is_default BOOLEAN, + uservisible BOOLEAN, + description TEXT, + langonly TEXT, + biarchonly BOOLEAN, +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, group_id, tag_id), + UNIQUE (group_id,tag_id,active) +) WITHOUT OIDS; + +CREATE TABLE group_req_listing ( + group_id INTEGER NOT NULL REFERENCES groups (id), + tag_id INTEGER NOT NULL REFERENCES tag (id), + req_id INTEGER NOT NULL REFERENCES groups (id), + blocked BOOLEAN NOT NULL DEFAULT FALSE, + type VARCHAR(25), + is_metapkg BOOLEAN NOT NULL DEFAULT FALSE, +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, group_id, tag_id, req_id), + UNIQUE (group_id,tag_id,req_id,active) +) WITHOUT OIDS; + +-- if blocked is true, then the package is specifically not included. this +-- prevents the package from being included in the group via inheritance +-- package refers to an rpm name, not necessarily an srpm name (so it does +-- not reference the package table). +CREATE TABLE group_package_listing ( + group_id INTEGER NOT NULL REFERENCES groups (id), + tag_id INTEGER NOT NULL REFERENCES tag (id), + package TEXT, + blocked BOOLEAN NOT NULL DEFAULT FALSE, + type VARCHAR(25) NOT NULL, + basearchonly BOOLEAN, + requires TEXT, +-- versioned - see earlier description of versioning + create_event INTEGER NOT NULL REFERENCES events(id) DEFAULT get_event(), + revoke_event INTEGER REFERENCES events(id), + creator_id INTEGER NOT NULL REFERENCES users(id), + revoker_id INTEGER REFERENCES users(id), + active BOOLEAN DEFAULT 'true' CHECK (active), + CONSTRAINT active_revoke_sane CHECK ( + (active IS NULL AND revoke_event IS NOT NULL AND revoker_id IS NOT NULL) + OR (active IS NOT NULL AND revoke_event IS NULL AND revoker_id IS NULL)), + PRIMARY KEY (create_event, group_id, tag_id, package), + UNIQUE (group_id,tag_id,package,active) +) WITHOUT OIDS; + +-- rpminfo tracks individual rpms (incl srpms) +-- buildroot_id can be NULL (for externally built packages) +-- even though we track epoch, we demand that N-V-R.A be unique +-- we don't store filename b/c filename should be N-V-R.A.rpm +CREATE TABLE rpminfo ( + id SERIAL NOT NULL PRIMARY KEY, + build_id INTEGER REFERENCES build (id), + buildroot_id INTEGER REFERENCES buildroot (id), + name TEXT NOT NULL, + version TEXT NOT NULL, + release TEXT NOT NULL, + epoch INTEGER, + arch VARCHAR(16) NOT NULL, + external_repo_id INTEGER NOT NULL REFERENCES external_repo(id), + payloadhash TEXT NOT NULL, + size BIGINT NOT NULL, + buildtime BIGINT NOT NULL, + metadata_only BOOLEAN NOT NULL DEFAULT FALSE, + extra TEXT, + CONSTRAINT rpminfo_unique_nvra UNIQUE (name,version,release,arch,external_repo_id) +) WITHOUT OIDS; +CREATE INDEX rpminfo_build ON rpminfo(build_id); +-- index for default search method for rpms, PG11+ can benefit from new include method +DO $$ + DECLARE version integer; + BEGIN + SELECT current_setting('server_version_num')::integer INTO version; + IF version >= 110000 THEN + EXECUTE 'CREATE INDEX rpminfo_filename ON rpminfo((name || ''-'' || version || ''-'' || release || ''.'' || arch || ''.rpm'')) INCLUDE (id);'; + ELSE + EXECUTE 'CREATE INDEX rpminfo_filename ON rpminfo((name || ''-'' || version || ''-'' || release || ''.'' || arch || ''.rpm''));'; + END IF; + END +$$; + +-- sighash is the checksum of the signature header +CREATE TABLE rpmsigs ( + rpm_id INTEGER NOT NULL REFERENCES rpminfo (id), + sigkey TEXT NOT NULL, + sighash TEXT NOT NULL, + CONSTRAINT rpmsigs_no_resign UNIQUE (rpm_id, sigkey) +) WITHOUT OIDS; + +-- buildroot_listing needs to be created after rpminfo so it can reference it +CREATE TABLE buildroot_listing ( + buildroot_id INTEGER NOT NULL REFERENCES buildroot(id), + rpm_id INTEGER NOT NULL REFERENCES rpminfo(id), + is_update BOOLEAN NOT NULL DEFAULT FALSE, + UNIQUE (buildroot_id,rpm_id) +) WITHOUT OIDS; +CREATE INDEX buildroot_listing_rpms ON buildroot_listing(rpm_id); + +CREATE TABLE build_notifications ( + id SERIAL NOT NULL PRIMARY KEY, + user_id INTEGER NOT NULL REFERENCES users (id), + package_id INTEGER REFERENCES package (id), + tag_id INTEGER REFERENCES tag (id), + success_only BOOLEAN NOT NULL DEFAULT FALSE, + email TEXT NOT NULL +) WITHOUT OIDS; + +CREATE TABLE build_notifications_block ( + id SERIAL NOT NULL PRIMARY KEY, + user_id INTEGER NOT NULL REFERENCES users (id), + package_id INTEGER REFERENCES package (id), + tag_id INTEGER REFERENCES tag (id) +) WITHOUT OIDS; + +GRANT SELECT ON build, package, task, tag, +tag_listing, tag_config, tag_inheritance, tag_packages, +rpminfo TO PUBLIC; + +-- example code to add initial admins +-- insert into users (name, usertype, status, krb_principal) values ('admin', 0, 0, 'admin@EXAMPLE.COM'); +-- insert into user_perms (user_id, perm_id) +-- select users.id, permissions.id from users, permissions +-- where users.name in ('admin') +-- and permissions.name = 'admin'; + +-- Schema additions for multiplatform support + +-- we need to track some additional metadata about Maven builds +CREATE TABLE maven_builds ( + build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id), + group_id TEXT NOT NULL, + artifact_id TEXT NOT NULL, + version TEXT NOT NULL +) WITHOUT OIDS; + +-- Windows-specific build information +CREATE TABLE win_builds ( + build_id INTEGER NOT NULL PRIMARY KEY REFERENCES build(id), + platform TEXT NOT NULL +) WITHOUT OIDS; + +-- Even though we call this archiveinfo, we can probably use it for +-- any filetype output by a build process. In general they will be +-- archives (.zip, .jar, .tar.gz) but could also be installer executables (.exe) +CREATE TABLE archivetypes ( + id SERIAL NOT NULL PRIMARY KEY, + name TEXT NOT NULL UNIQUE, + description TEXT NOT NULL, + extensions TEXT NOT NULL, + compression_type TEXT +) WITHOUT OIDS; + +INSERT INTO archivetypes (name, description, extensions, compression_type) VALUES ('jar', 'Jar file', 'jar war rar ear sar jdocbook jdocbook-style', 'zip'); +INSERT INTO archivetypes (name, description, extensions, compression_type) VALUES ('zip', 'Zip file', 'zip', 'zip'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('pom', 'Maven Project Object Management file', 'pom'); +INSERT INTO archivetypes (name, description, extensions, compression_type) VALUES ('tar', 'Tar file', 'tar tar.gz tar.bz2 tar.xz tgz', 'tar'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('xml', 'XML file', 'xml'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('xmlcompressed', 'Compressed XML file', 'xml.gz xml.bz2 xml.xz'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('xsd', 'XML Schema Definition', 'xsd'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('spec', 'RPM spec file', 'spec'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('exe', 'Windows executable', 'exe'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('dll', 'Windows dynamic link library', 'dll'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('lib', 'Windows import library', 'lib'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('sys', 'Windows device driver', 'sys'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('inf', 'Windows driver information file', 'inf'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('cat', 'Windows catalog file', 'cat'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('msi', 'Windows Installer package', 'msi'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('pdb', 'Windows debug information', 'pdb'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('oem', 'Windows driver oem file', 'oem'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('iso', 'CD/DVD Image', 'iso'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('raw', 'Raw disk image', 'raw'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('qcow', 'QCOW image', 'qcow'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('qcow2', 'QCOW2 image', 'qcow2'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('vmdk', 'vSphere image', 'vmdk'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('ova', 'Open Virtualization Archive', 'ova'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('ks', 'Kickstart', 'ks'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('cfg', 'Configuration file', 'cfg'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('vdi', 'VirtualBox Virtual Disk Image', 'vdi'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('aar', 'Binary distribution of an Android Library project', 'aar'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('apklib', 'Source distribution of an Android Library project', 'apklib'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('cab', 'Windows cabinet file', 'cab'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('dylib', 'OS X dynamic library', 'dylib'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('gem', 'Ruby gem', 'gem'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('ini', 'INI config file', 'ini'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('js', 'Javascript file', 'js'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('ldif', 'LDAP Data Interchange Format file', 'ldif'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('manifest', 'Runtime environment for .NET applications', 'manifest'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('msm', 'Windows merge module', 'msm'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('properties', 'Properties file', 'properties'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('sig', 'Signature file', 'sig signature'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('so', 'Shared library', 'so'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('txt', 'Text file', 'txt'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('vhd', 'Hyper-V image', 'vhd'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('vhdx', 'Hyper-V Virtual Hard Disk v2 image', 'vhdx'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('wsf', 'Windows script file', 'wsf'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('box', 'Vagrant Box Image', 'box'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('raw-xz', 'xz compressed raw disk image', 'raw.xz'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('json', 'JSON data', 'json'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('key', 'Key file', 'key'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('dot', 'DOT graph description', 'dot gv'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('groovy', 'Groovy script file', 'groovy gvy'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('batch', 'Batch file', 'bat'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('shell', 'Shell script', 'sh'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('rc', 'Resource file', 'rc'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('wsdl', 'Web Services Description Language', 'wsdl'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('obr', 'OSGi Bundle Repository', 'obr'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('liveimg-squashfs', 'liveimg compatible squashfs image', 'liveimg.squashfs'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('tlb', 'OLE type library file', 'tlb'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('jnilib', 'Java Native Interface library', 'jnilib'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('yaml', 'YAML Ain''t Markup Language', 'yaml yml'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('xjb', 'JAXB(Java Architecture for XML Binding) Binding Customization File', 'xjb'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('raw-gz', 'GZIP compressed raw disk image', 'raw.gz'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('qcow2-compressed', 'Compressed QCOW2 image', 'qcow2.gz qcow2.xz'); +-- add compressed iso-compressed, vhd-compressed, vhdx-compressed, and vmdk-compressed: From schema-upgrade-1.18-1.19 +INSERT INTO archivetypes (name, description, extensions) VALUES ('iso-compressed', 'Compressed iso image', 'iso.gz iso.xz'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('vhd-compressed', 'Compressed VHD image', 'vhd.gz vhd.xz'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('vhdx-compressed', 'Compressed VHDx image', 'vhdx.gz vhdx.xz'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('vmdk-compressed', 'Compressed VMDK image', 'vmdk.gz vmdk.xz'); +-- add kernel-image and imitramfs: From schema-upgrade-1.18-1.19 +INSERT INTO archivetypes (name, description, extensions) VALUES ('kernel-image', 'Kernel BZ2 Image', 'vmlinuz vmlinuz.gz vmlinuz.xz'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('initramfs', 'Compressed Initramfs Image', 'img'); +-- kiwi plugin +INSERT INTO archivetypes (name, description, extensions) VALUES ('checksum', 'Checksum file', 'sha256'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('changes', 'Kiwi changes file', 'changes.xz changes'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('packages', 'Kiwi packages listing', 'packages'); +INSERT INTO archivetypes (name, description, extensions) VALUES ('verified', 'Kiwi verified package list', 'verified'); + + +-- Do we want to enforce a constraint that a build can only generate one +-- archive with a given name? +CREATE TABLE archiveinfo ( + id SERIAL NOT NULL PRIMARY KEY, + type_id INTEGER NOT NULL REFERENCES archivetypes (id), + btype_id INTEGER REFERENCES btype(id), + -- ^ TODO add NOT NULL + build_id INTEGER NOT NULL REFERENCES build (id), + buildroot_id INTEGER REFERENCES buildroot (id), + filename TEXT NOT NULL, + size BIGINT NOT NULL, + checksum TEXT NOT NULL, + checksum_type INTEGER NOT NULL, + metadata_only BOOLEAN NOT NULL DEFAULT FALSE, + extra TEXT +) WITHOUT OIDS; +CREATE INDEX archiveinfo_build_idx ON archiveinfo (build_id); +CREATE INDEX archiveinfo_buildroot_idx on archiveinfo (buildroot_id); +CREATE INDEX archiveinfo_type_idx on archiveinfo (type_id); +CREATE INDEX archiveinfo_filename_idx on archiveinfo(filename); + +CREATE TABLE maven_archives ( + archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), + group_id TEXT NOT NULL, + artifact_id TEXT NOT NULL, + version TEXT NOT NULL +) WITHOUT OIDS; + +CREATE TABLE image_archives ( + archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), + arch VARCHAR(16) NOT NULL +) WITHOUT OIDS; + +-- tracks the rpm contents of an image or other archive +CREATE TABLE archive_rpm_components ( + archive_id INTEGER NOT NULL REFERENCES archiveinfo(id), + rpm_id INTEGER NOT NULL REFERENCES rpminfo(id), + UNIQUE (archive_id, rpm_id) +) WITHOUT OIDS; +CREATE INDEX rpm_components_idx on archive_rpm_components(rpm_id); + +-- track the archive contents of an image or other archive +CREATE TABLE archive_components ( + archive_id INTEGER NOT NULL REFERENCES archiveinfo(id), + component_id INTEGER NOT NULL REFERENCES archiveinfo(id), + UNIQUE (archive_id, component_id) +) WITHOUT OIDS; +CREATE INDEX archive_components_idx on archive_components(component_id); + + +CREATE TABLE buildroot_archives ( + buildroot_id INTEGER NOT NULL REFERENCES buildroot (id), + archive_id INTEGER NOT NULL REFERENCES archiveinfo (id), + project_dep BOOLEAN NOT NULL, + PRIMARY KEY (buildroot_id, archive_id) +) WITHOUT OIDS; +CREATE INDEX buildroot_archives_archive_idx ON buildroot_archives (archive_id); + +-- Extended information about files built in Windows VMs +CREATE TABLE win_archives ( + archive_id INTEGER NOT NULL PRIMARY KEY REFERENCES archiveinfo(id), + relpath TEXT NOT NULL, + platforms TEXT NOT NULL, + flags TEXT +) WITHOUT OIDS; + + +-- Message queue for the protonmsg plugin +CREATE TABLE proton_queue ( + id SERIAL PRIMARY KEY, + created_ts TIMESTAMPTZ DEFAULT NOW(), + address TEXT NOT NULL, + props JSON NOT NULL, + body JSON NOT NULL +) WITHOUT OIDS; + +-- track checksum of rpms +CREATE TABLE rpm_checksum ( + rpm_id INTEGER NOT NULL REFERENCES rpminfo(id), + sigkey TEXT NOT NULL, + checksum TEXT NOT NULL UNIQUE, + checksum_type SMALLINT NOT NULL, + PRIMARY KEY (rpm_id, sigkey, checksum_type) +) WITHOUT OIDS; +CREATE INDEX rpm_checksum_rpm_id ON rpm_checksum(rpm_id); + +-- this table is used for locking, see db_lock() +CREATE TABLE locks ( + name TEXT NOT NULL PRIMARY KEY +) WITHOUT OIDS; +INSERT INTO locks(name) VALUES('protonmsg-plugin'); + +COMMIT WORK;