From 64284ee96a521961d9a0c25f682bc5d63d2a8c3f Mon Sep 17 00:00:00 2001 From: Markus Frosch Date: Fri, 25 Nov 2016 08:49:40 +0100 Subject: [PATCH] Add schema migration for ServiceSet foreign keys This will clean up dangling service_set for non-existing host and service for service_set refs #13309 --- schema/mysql-migrations/upgrade_123.sql | 30 +++++++++++++++++++ schema/mysql.sql | 34 +++++++++++++-------- schema/pgsql-migrations/upgrade_123.sql | 34 +++++++++++++++++++++ schema/pgsql.sql | 39 ++++++++++++++++--------- 4 files changed, 111 insertions(+), 26 deletions(-) create mode 100644 schema/mysql-migrations/upgrade_123.sql create mode 100644 schema/pgsql-migrations/upgrade_123.sql diff --git a/schema/mysql-migrations/upgrade_123.sql b/schema/mysql-migrations/upgrade_123.sql new file mode 100644 index 00000000..80b24fa4 --- /dev/null +++ b/schema/mysql-migrations/upgrade_123.sql @@ -0,0 +1,30 @@ +-- cleanup dangling service_set before we add foreign key +DELETE ss FROM icinga_service_set AS ss + LEFT JOIN icinga_host AS h ON h.id = ss.host_id + WHERE ss.object_type = 'object' + AND ss.host_id IS NOT NULL + AND h.id IS NULL; + +-- cleanup dangling services to service_set +DELETE s FROM icinga_service AS s + LEFT JOIN icinga_service_set AS ss ON ss.id = s.service_set_id + WHERE s.object_type = 'object' + AND s.service_set_id IS NOT NULL + AND ss.id IS NULL; + + +ALTER TABLE icinga_service_set + ADD FOREIGN KEY icinga_service_set_host (host_id) + REFERENCES icinga_host (id) + ON DELETE RESTRICT + ON UPDATE CASCADE; + +ALTER TABLE icinga_service + ADD FOREIGN KEY icinga_service_service_set (service_set_id) + REFERENCES icinga_service_set (id) + ON DELETE RESTRICT + ON UPDATE CASCADE; + +INSERT INTO director_schema_migration +(schema_version, migration_time) +VALUES (123, NOW()); diff --git a/schema/mysql.sql b/schema/mysql.sql index ce7678e7..4fecf709 100644 --- a/schema/mysql.sql +++ b/schema/mysql.sql @@ -529,6 +529,22 @@ CREATE TABLE icinga_host_var ( ON UPDATE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8; +CREATE TABLE icinga_service_set ( + id INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, + object_name VARCHAR(128) NOT NULL, + 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), + CONSTRAINT icinga_service_set_host + FOREIGN KEY host (host_id) + REFERENCES icinga_host (id) + ON DELETE RESTRICT + ON UPDATE CASCADE +) ENGINE=InnoDB DEFAULT CHARSET=utf8; + CREATE TABLE icinga_service ( id INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, object_name VARCHAR(255) NOT NULL, @@ -593,6 +609,11 @@ CREATE TABLE icinga_service ( FOREIGN KEY command_endpoint (command_endpoint_id) REFERENCES icinga_endpoint (id) ON DELETE RESTRICT + ON UPDATE CASCADE, + CONSTRAINT icinga_service_service_set + FOREIGN KEY service_set (service_set_id) + REFERENCES icinga_service_set (id) + ON DELETE RESTRICT ON UPDATE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8; @@ -661,17 +682,6 @@ CREATE TABLE icinga_host_service ( ON UPDATE CASCADE ) ENGINE=InnoDB; -CREATE TABLE icinga_service_set ( - id INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, - object_name VARCHAR(128) NOT NULL, - 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; - CREATE TABLE icinga_service_set_inheritance ( service_set_id INT(10) UNSIGNED NOT NULL, parent_service_set_id INT(10) UNSIGNED NOT NULL, @@ -1355,4 +1365,4 @@ CREATE TABLE sync_run ( INSERT INTO director_schema_migration (schema_version, migration_time) - VALUES (122, NOW()); + VALUES (123, NOW()); diff --git a/schema/pgsql-migrations/upgrade_123.sql b/schema/pgsql-migrations/upgrade_123.sql new file mode 100644 index 00000000..77005f82 --- /dev/null +++ b/schema/pgsql-migrations/upgrade_123.sql @@ -0,0 +1,34 @@ +-- cleanup dangling service_set before we add foreign key +DELETE FROM icinga_service_set AS ss + WHERE NOT EXISTS ( + SELECT 1 FROM icinga_host AS h + WHERE h.id = ss.host_id + ) + AND object_type = 'object' + AND host_id IS NOT NULL; + +-- cleanup dangling services to service_set +DELETE FROM icinga_service AS s + WHERE NOT EXISTS ( + SELECT 1 FROM icinga_service_set AS ss + WHERE ss.id = s.service_set_id + ) + AND object_type = 'object' + AND service_set_id IS NOT NULL; + + +ALTER TABLE icinga_service_set + ADD CONSTRAINT icinga_service_set_host FOREIGN KEY (host_id) + REFERENCES icinga_host (id) + ON DELETE RESTRICT + ON UPDATE CASCADE; + +ALTER TABLE icinga_service + ADD CONSTRAINT icinga_service_service_set FOREIGN KEY (service_set_id) + REFERENCES icinga_service_set (id) + ON DELETE RESTRICT + ON UPDATE CASCADE; + +INSERT INTO director_schema_migration + (schema_version, migration_time) + VALUES (123, NOW()); diff --git a/schema/pgsql.sql b/schema/pgsql.sql index e3198bcd..099b73fe 100644 --- a/schema/pgsql.sql +++ b/schema/pgsql.sql @@ -671,6 +671,25 @@ CREATE INDEX host_var_search_idx ON icinga_host_var (varname); CREATE INDEX host_var_host ON icinga_host_var (host_id); +CREATE TABLE icinga_service_set ( + id serial, + host_id integer DEFAULT NULL, + 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), + CONSTRAINT icinga_service_set_host + FOREIGN KEY (host_id) + REFERENCES icinga_host (id) + ON DELETE RESTRICT + ON UPDATE CASCADE +); + +CREATE UNIQUE INDEX service_set_name ON icinga_service_set (object_name, host_id); +CREATE INDEX service_set_host ON icinga_service_set (host_id); + + CREATE TABLE icinga_service ( id serial, object_name character varying(255) NOT NULL, @@ -735,6 +754,11 @@ CREATE TABLE icinga_service ( FOREIGN KEY (command_endpoint_id) REFERENCES icinga_endpoint (id) ON DELETE RESTRICT + ON UPDATE CASCADE, + CONSTRAINT icinga_service_service_set + FOREIGN KEY (service_set_id) + REFERENCES icinga_service_set (id) + ON DELETE RESTRICT ON UPDATE CASCADE ); @@ -827,19 +851,6 @@ CREATE INDEX host_service_host ON icinga_host_service (host_id); CREATE INDEX host_service_service ON icinga_host_service (service_id); -CREATE TABLE icinga_service_set ( - id serial, - host_id integer DEFAULT NULL, - 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) -); - -CREATE UNIQUE INDEX service_set_name ON icinga_service_set (object_name, host_id); - - CREATE TABLE icinga_service_set_inheritance ( service_set_id integer NOT NULL, parent_service_set_id integer NOT NULL, @@ -1582,4 +1593,4 @@ CREATE UNIQUE INDEX notification_inheritance ON icinga_notification_inheritance INSERT INTO director_schema_migration (schema_version, migration_time) - VALUES (122, NOW()); + VALUES (123, NOW());