From 47cd8cdc89669a2854a2788c4ca6b7e62bdaa5cc Mon Sep 17 00:00:00 2001 From: Thomas Gelf Date: Tue, 25 Oct 2016 02:00:50 +0000 Subject: [PATCH] schema: add assign_type migrations for pgsql... ...and complete them for mysql --- schema/mysql-migrations/upgrade_120.sql | 10 +- schema/mysql.sql | 61 +------ schema/pgsql-migrations/upgrade_120.sql | 201 ++++++++++++++++++++++++ schema/pgsql.sql | 62 +------- 4 files changed, 219 insertions(+), 115 deletions(-) create mode 100644 schema/pgsql-migrations/upgrade_120.sql diff --git a/schema/mysql-migrations/upgrade_120.sql b/schema/mysql-migrations/upgrade_120.sql index 7fca2816..4020deaa 100644 --- a/schema/mysql-migrations/upgrade_120.sql +++ b/schema/mysql-migrations/upgrade_120.sql @@ -1,4 +1,4 @@ -ALTER TABLE icinga_service ADD COLUMN assign_filter TEXT; +ALTER TABLE icinga_service ADD COLUMN assign_filter TEXT DEFAULT NULL; UPDATE icinga_service s JOIN ( @@ -42,7 +42,7 @@ UPDATE icinga_service s JOIN ( DROP TABLE icinga_service_assignment; -ALTER TABLE icinga_service_set ADD COLUMN assign_filter TEXT; +ALTER TABLE icinga_service_set ADD COLUMN assign_filter TEXT DEFAULT NULL; UPDATE icinga_service_set s JOIN ( @@ -87,7 +87,7 @@ UPDATE icinga_service_set s JOIN ( DROP TABLE icinga_service_set_assignment; -ALTER TABLE icinga_notification ADD COLUMN assign_filter TEXT; +ALTER TABLE icinga_notification ADD COLUMN assign_filter TEXT DEFAULT NULL; UPDATE icinga_notification s JOIN ( @@ -131,7 +131,7 @@ UPDATE icinga_notification s JOIN ( DROP TABLE icinga_notification_assignment; -ALTER TABLE icinga_hostgroup ADD COLUMN assign_filter TEXT; +ALTER TABLE icinga_hostgroup ADD COLUMN assign_filter TEXT DEFAULT NULL; UPDATE icinga_hostgroup s JOIN ( @@ -176,7 +176,7 @@ UPDATE icinga_hostgroup s JOIN ( DROP TABLE icinga_hostgroup_assignment; -ALTER TABLE icinga_servicegroup ADD COLUMN assign_filter TEXT; +ALTER TABLE icinga_servicegroup ADD COLUMN assign_filter TEXT DEFAULT NULL; INSERT INTO director_schema_migration diff --git a/schema/mysql.sql b/schema/mysql.sql index 6c233bbd..c6a4932f 100644 --- a/schema/mysql.sql +++ b/schema/mysql.sql @@ -559,6 +559,7 @@ CREATE TABLE icinga_service ( use_agent ENUM('y', 'n') DEFAULT NULL, apply_for VARCHAR(255) DEFAULT NULL, use_var_overrides ENUM('y', 'n') DEFAULT NULL, + assign_filter TEXT DEFAULT NULL, PRIMARY KEY (id), UNIQUE KEY object_key (object_name, host_id), CONSTRAINT icinga_service_host @@ -642,19 +643,6 @@ CREATE TABLE icinga_service_field ( ON UPDATE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8; -CREATE TABLE icinga_service_assignment ( - id INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, - service_id INT(10) UNSIGNED NOT NULL, - filter_string TEXT NOT NULL, - assign_type ENUM('assign', 'ignore') NOT NULL DEFAULT 'assign', - PRIMARY KEY (id), - CONSTRAINT icinga_service_assignment - FOREIGN KEY service (service_id) - REFERENCES icinga_service (id) - ON DELETE CASCADE - ON UPDATE CASCADE -) ENGINE=InnoDB; - CREATE TABLE icinga_host_service ( host_id INT(10) UNSIGNED NOT NULL, service_id INT(10) UNSIGNED NOT NULL, @@ -677,6 +665,7 @@ CREATE TABLE icinga_service_set ( object_type ENUM('object', 'template', 'external_object') NOT NULL, host_id INT(10) UNSIGNED DEFAULT NULL, description TEXT DEFAULT NULL, + assign_filter TEXT DEFAULT NULL, PRIMARY KEY (id), UNIQUE KEY object_key (object_name, host_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; @@ -715,19 +704,6 @@ CREATE TABLE icinga_service_set_inheritance ( ON UPDATE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8; -CREATE TABLE icinga_service_set_assignment ( - id INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, - service_set_id INT(10) UNSIGNED NOT NULL, - filter_string TEXT NOT NULL, - assign_type ENUM('assign', 'ignore') NOT NULL DEFAULT 'assign', - PRIMARY KEY (id), - CONSTRAINT icinga_service_set_assignment - FOREIGN KEY service_set (service_set_id) - REFERENCES icinga_service_set (id) - ON DELETE CASCADE - ON UPDATE CASCADE -) ENGINE=InnoDB; - CREATE TABLE icinga_service_set_var ( service_set_id INT(10) UNSIGNED NOT NULL, varname VARCHAR(255) NOT NULL COLLATE utf8_bin, @@ -747,6 +723,7 @@ CREATE TABLE icinga_hostgroup ( object_type ENUM('object', 'template') NOT NULL, disabled ENUM('y', 'n') NOT NULL DEFAULT 'n', display_name VARCHAR(255) DEFAULT NULL, + assign_filter TEXT DEFAULT NULL, PRIMARY KEY (id), UNIQUE INDEX object_name (object_name), KEY search_idx (display_name) @@ -771,25 +748,13 @@ CREATE TABLE icinga_hostgroup_inheritance ( ON UPDATE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8; -CREATE TABLE icinga_hostgroup_assignment ( - id INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, - hostgroup_id INT(10) UNSIGNED NOT NULL, - filter_string TEXT NOT NULL, - assign_type ENUM('assign', 'ignore') NOT NULL DEFAULT 'assign', - PRIMARY KEY (id), - CONSTRAINT icinga_hostgroup_assignment - FOREIGN KEY hostgroup (hostgroup_id) - REFERENCES icinga_hostgroup (id) - ON DELETE CASCADE - ON UPDATE CASCADE -) ENGINE=InnoDB; - CREATE TABLE icinga_servicegroup ( id INT(10) UNSIGNED AUTO_INCREMENT NOT NULL, object_name VARCHAR(255) DEFAULT NULL, object_type ENUM('object', 'template') NOT NULL, disabled ENUM('y', 'n') NOT NULL DEFAULT 'n', display_name VARCHAR(255) DEFAULT NULL, + assign_filter TEXT DEFAULT NULL, PRIMARY KEY (id), UNIQUE INDEX object_name (object_name), KEY search_idx (display_name) @@ -1048,6 +1013,7 @@ CREATE TABLE icinga_notification ( command_id INT(10) UNSIGNED DEFAULT NULL, period_id INT(10) UNSIGNED DEFAULT NULL, zone_id INT(10) UNSIGNED DEFAULT NULL, + assign_filter TEXT DEFAULT NULL, PRIMARY KEY (id), CONSTRAINT icinga_notification_host FOREIGN KEY host (host_id) @@ -1168,19 +1134,6 @@ CREATE TABLE icinga_notification_types_set ( ON UPDATE CASCADE ) ENGINE=InnoDB; -CREATE TABLE icinga_notification_assignment ( - id INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, - notification_id INT(10) UNSIGNED NOT NULL, - filter_string TEXT NOT NULL, - assign_type ENUM('assign', 'ignore') NOT NULL DEFAULT 'assign', - PRIMARY KEY (id), - CONSTRAINT icinga_notification_assignment - FOREIGN KEY notification (notification_id) - REFERENCES icinga_notification (id) - ON DELETE CASCADE - ON UPDATE CASCADE -) ENGINE=InnoDB; - CREATE TABLE icinga_notification_user ( notification_id INT(10) UNSIGNED NOT NULL, user_id INT(10) UNSIGNED NOT NULL, @@ -1415,5 +1368,5 @@ CREATE TABLE sync_run ( ) ENGINE=InnoDB DEFAULT CHARSET=utf8; INSERT INTO director_schema_migration - SET migration_time = NOW(), - schema_version = 119; + (schema_version, migration_time) + VALUES (120, NOW()); diff --git a/schema/pgsql-migrations/upgrade_120.sql b/schema/pgsql-migrations/upgrade_120.sql new file mode 100644 index 00000000..94d7364c --- /dev/null +++ b/schema/pgsql-migrations/upgrade_120.sql @@ -0,0 +1,201 @@ +ALTER TABLE icinga_service ADD COLUMN assign_filter text DEFAULT NULL; + +WITH flat_assign AS ( + + SELECT + service_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa.filter_string) + ELSE ARRAY_TO_STRING(ARRAY_AGG(sa.filter_string), '&') END AS filter_string + FROM ( + SELECT + sa_not.service_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa_not.filter_string) + ELSE '(' || ARRAY_TO_STRING(ARRAY_AGG(sa_not.filter_string), '&') || ')' END AS filter_string + FROM ( SELECT + sa.service_id, + '!' || sa.filter_string AS filter_string + FROM icinga_service_assignment sa + WHERE assign_type = 'ignore' + ) sa_not + GROUP BY service_id + + UNION ALL + + SELECT + sa_yes.service_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa_yes.filter_string) + ELSE '(' || ARRAY_TO_STRING(ARRAY_AGG(sa_yes.filter_string), '|') || ')' END AS filter_string + FROM ( SELECT + sa.service_id, + sa.filter_string AS filter_string + FROM icinga_service_assignment sa + WHERE assign_type = 'assign' + ) sa_yes + GROUP BY service_id + + ) sa GROUP BY service_id + +) UPDATE icinga_service s + SET assign_filter = flat_assign.filter_string + FROM flat_assign + WHERE s.id = flat_assign.service_id; + +DROP TABLE icinga_service_assignment; + +ALTER TABLE icinga_service_set ADD COLUMN assign_filter text DEFAULT NULL; + +WITH flat_assign AS ( + + SELECT + service_set_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa.filter_string) + ELSE ARRAY_TO_STRING(ARRAY_AGG(sa.filter_string), '&') END AS filter_string + FROM ( + SELECT + sa_not.service_set_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa_not.filter_string) + ELSE '(' || ARRAY_TO_STRING(ARRAY_AGG(sa_not.filter_string), '&') || ')' END AS filter_string + FROM ( SELECT + sa.service_set_id, + '!' || sa.filter_string AS filter_string + FROM icinga_service_set_assignment sa + WHERE assign_type = 'ignore' + ) sa_not + GROUP BY service_set_id + + UNION ALL + + SELECT + sa_yes.service_set_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa_yes.filter_string) + ELSE '(' || ARRAY_TO_STRING(ARRAY_AGG(sa_yes.filter_string), '|') || ')' END AS filter_string + FROM ( SELECT + sa.service_set_id, + sa.filter_string AS filter_string + FROM icinga_service_set_assignment sa + WHERE assign_type = 'assign' + ) sa_yes + GROUP BY service_set_id + + ) sa GROUP BY service_set_id + +) UPDATE icinga_service_set s + SET assign_filter = flat_assign.filter_string + FROM flat_assign + WHERE s.id = flat_assign.service_set_id; + +DROP TABLE icinga_service_set_assignment; + + +ALTER TABLE icinga_notification ADD COLUMN assign_filter text DEFAULT NULL; + +WITH flat_assign AS ( + + SELECT + notification_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa.filter_string) + ELSE ARRAY_TO_STRING(ARRAY_AGG(sa.filter_string), '&') END AS filter_string + FROM ( + SELECT + sa_not.notification_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa_not.filter_string) + ELSE '(' || ARRAY_TO_STRING(ARRAY_AGG(sa_not.filter_string), '&') || ')' END AS filter_string + FROM ( SELECT + sa.notification_id, + '!' || sa.filter_string AS filter_string + FROM icinga_notification_assignment sa + WHERE assign_type = 'ignore' + ) sa_not + GROUP BY notification_id + + UNION ALL + + SELECT + sa_yes.notification_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa_yes.filter_string) + ELSE '(' || ARRAY_TO_STRING(ARRAY_AGG(sa_yes.filter_string), '|') || ')' END AS filter_string + FROM ( SELECT + sa.notification_id, + sa.filter_string AS filter_string + FROM icinga_notification_assignment sa + WHERE assign_type = 'assign' + ) sa_yes + GROUP BY notification_id + + ) sa GROUP BY notification_id + +) UPDATE icinga_notification s + SET assign_filter = flat_assign.filter_string + FROM flat_assign + WHERE s.id = flat_assign.notification_id; + + +DROP TABLE icinga_notification_assignment; + +ALTER TABLE icinga_hostgroup ADD COLUMN assign_filter text DEFAULT NULL; + +WITH flat_assign AS ( + + SELECT + hostgroup_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa.filter_string) + ELSE ARRAY_TO_STRING(ARRAY_AGG(sa.filter_string), '&') END AS filter_string + FROM ( + SELECT + sa_not.hostgroup_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa_not.filter_string) + ELSE '(' || ARRAY_TO_STRING(ARRAY_AGG(sa_not.filter_string), '&') || ')' END AS filter_string + FROM ( SELECT + sa.hostgroup_id, + '!' || sa.filter_string AS filter_string + FROM icinga_hostgroup_assignment sa + WHERE assign_type = 'ignore' + ) sa_not + GROUP BY hostgroup_id + + UNION ALL + + SELECT + sa_yes.hostgroup_id, + CASE WHEN COUNT(*) = 0 THEN NULL + WHEN COUNT(*) = 1 THEN MAX(sa_yes.filter_string) + ELSE '(' || ARRAY_TO_STRING(ARRAY_AGG(sa_yes.filter_string), '|') || ')' END AS filter_string + FROM ( SELECT + sa.hostgroup_id, + sa.filter_string AS filter_string + FROM icinga_hostgroup_assignment sa + WHERE assign_type = 'assign' + ) sa_yes + GROUP BY hostgroup_id + + ) sa GROUP BY hostgroup_id + +) UPDATE icinga_hostgroup s + SET assign_filter = flat_assign.filter_string + FROM flat_assign + WHERE s.id = flat_assign.hostgroup_id; + + +DROP TABLE icinga_hostgroup_assignment; + + +ALTER TABLE icinga_servicegroup ADD COLUMN assign_filter text DEFAULT NULL; + + +DROP TYPE enum_assign_type; + + +INSERT INTO director_schema_migration + (schema_version, migration_time) + VALUES (120, NOW()); diff --git a/schema/pgsql.sql b/schema/pgsql.sql index 2594581c..2f2cea04 100644 --- a/schema/pgsql.sql +++ b/schema/pgsql.sql @@ -19,7 +19,6 @@ CREATE TYPE enum_command_object_type AS ENUM('object', 'template', 'external_obj CREATE TYPE enum_apply_object_type AS ENUM('object', 'template', 'apply', 'external_object'); CREATE TYPE enum_state_name AS ENUM('OK', 'Warning', 'Critical', 'Unknown', 'Up', 'Down'); CREATE TYPE enum_type_name AS ENUM('DowntimeStart', 'DowntimeEnd', 'DowntimeRemoved', 'Custom', 'Acknowledgement', 'Problem', 'Recovery', 'FlappingStart', 'FlappingEnd'); -CREATE TYPE enum_assign_type AS ENUM('assign', 'ignore'); CREATE TYPE enum_sync_rule_object_type AS ENUM( 'host', 'service', @@ -702,6 +701,7 @@ CREATE TABLE icinga_service ( use_agent enum_boolean DEFAULT NULL, apply_for character varying(255) DEFAULT NULL, use_var_overrides enum_boolean DEFAULT NULL, + assign_filter text DEFAULT NULL, PRIMARY KEY (id), -- UNIQUE INDEX object_name (object_name, zone_id), CONSTRAINT icinga_service_host @@ -805,20 +805,6 @@ CREATE INDEX service_field_datafield ON icinga_service_field (datafield_id); COMMENT ON COLUMN icinga_service_field.service_id IS 'Makes only sense for templates'; -CREATE TABLE icinga_service_assignment ( - id bigserial, - service_id integer NOT NULL, - filter_string TEXT NOT NULL, - assign_type enum_assign_type NOT NULL DEFAULT 'assign', - PRIMARY KEY (id), - CONSTRAINT icinga_service_assignment - FOREIGN KEY (service_id) - REFERENCES icinga_service (id) - ON DELETE CASCADE - ON UPDATE CASCADE -); - - CREATE TABLE icinga_host_service ( host_id integer NOT NULL, service_id integer NOT NULL, @@ -845,6 +831,7 @@ CREATE TABLE icinga_service_set ( object_name character varying(128) NOT NULL, object_type enum_object_type_all NOT NULL, description text DEFAULT NULL, + assign_filter text DEFAULT NULL, PRIMARY KEY (id) ); @@ -890,20 +877,6 @@ CREATE INDEX service_set_inheritance_set ON icinga_service_set_inheritance (serv CREATE INDEX service_set_inheritance_parent ON icinga_service_set_inheritance (parent_service_set_id); -CREATE TABLE icinga_service_set_assignment ( - id serial, - service_set_id integer NOT NULL, - filter_string text NOT NULL, - assign_type enum_assign_type NOT NULL DEFAULT 'assign', - PRIMARY KEY (id), - CONSTRAINT icinga_service_set_assignment - FOREIGN KEY (service_set_id) - REFERENCES icinga_service_set (id) - ON DELETE CASCADE - ON UPDATE CASCADE -); - - CREATE TABLE icinga_service_set_var ( service_set_id integer NOT NULL, varname character varying(255) NOT NULL, @@ -927,6 +900,7 @@ CREATE TABLE icinga_hostgroup ( object_type enum_object_type_all NOT NULL, disabled enum_boolean NOT NULL DEFAULT 'n', display_name character varying(255) DEFAULT NULL, + assign_filter text DEFAULT NULL, PRIMARY KEY (id) ); @@ -956,18 +930,6 @@ CREATE UNIQUE INDEX hostgroup_inheritance_unique_order ON icinga_hostgroup_inher CREATE INDEX hostgroup_inheritance_hostgroup ON icinga_hostgroup_inheritance (hostgroup_id); CREATE INDEX hostgroup_inheritance_hostgroup_parent ON icinga_hostgroup_inheritance (parent_hostgroup_id); -CREATE TABLE icinga_hostgroup_assignment ( - id bigserial, - hostgroup_id integer NOT NULL, - filter_string TEXT NOT NULL, - assign_type enum_assign_type NOT NULL DEFAULT 'assign', - PRIMARY KEY (id), - CONSTRAINT icinga_hostgroup_assignment - FOREIGN KEY (hostgroup_id) - REFERENCES icinga_hostgroup (id) - ON DELETE CASCADE - ON UPDATE CASCADE -); CREATE TABLE icinga_servicegroup ( id serial, @@ -975,6 +937,7 @@ CREATE TABLE icinga_servicegroup ( object_type enum_object_type_all NOT NULL, disabled enum_boolean NOT NULL DEFAULT 'n', display_name character varying(255) DEFAULT NULL, + assign_filter text DEFAULT NULL, PRIMARY KEY (id) ); @@ -1270,6 +1233,7 @@ CREATE TABLE icinga_notification ( command_id integer DEFAULT NULL, period_id integer DEFAULT NULL, zone_id integer DEFAULT NULL, + assign_filter text DEFAULT NULL, PRIMARY KEY (id), CONSTRAINT icinga_notification_host FOREIGN KEY (host_id) @@ -1299,20 +1263,6 @@ CREATE TABLE icinga_notification ( ); -CREATE TABLE icinga_notification_assignment ( - id bigserial, - notification_id integer NOT NULL, - filter_string TEXT NOT NULL, - assign_type enum_assign_type NOT NULL DEFAULT 'assign', - PRIMARY KEY (id), - CONSTRAINT icinga_notification_assignment - FOREIGN KEY (notification_id) - REFERENCES icinga_notification (id) - ON DELETE CASCADE - ON UPDATE CASCADE -); - - CREATE TABLE icinga_notification_user ( notification_id integer NOT NULL, user_id integer NOT NULL, @@ -1647,4 +1597,4 @@ CREATE UNIQUE INDEX notification_inheritance ON icinga_notification_inheritance INSERT INTO director_schema_migration (schema_version, migration_time) - VALUES (119, NOW()); + VALUES (120, NOW());