From b07d784088eaa59fa141095a57ef15ee0f192704 Mon Sep 17 00:00:00 2001 From: Alvar Penning Date: Mon, 29 Jul 2024 15:14:08 +0200 Subject: [PATCH] schema: Fix values to fit by increasing type sizes The icon_image_alt column in both the host and service tables contains an image alt text. However, because it is defined as a varchar(32), many alt texts do not fit. The type has been expanded to text, as with most free text fields. Closes #752. When defining a TimePeriod, the maximum length of a range value was capped at 255 characters. This limitation has now also been removed by switching to the Text type. Closes #724. While re-reading the schema, I stumbled upon some missing properties_checksum comments that were also added. --- pkg/icingadb/schema.go | 4 ++-- schema/mysql/schema.sql | 12 ++++++------ schema/mysql/upgrades/1.2.1.sql | 11 +++++++++++ schema/pgsql/schema.sql | 9 ++++++--- schema/pgsql/upgrades/1.2.1.sql | 11 +++++++++++ 5 files changed, 36 insertions(+), 11 deletions(-) create mode 100644 schema/mysql/upgrades/1.2.1.sql create mode 100644 schema/pgsql/upgrades/1.2.1.sql diff --git a/pkg/icingadb/schema.go b/pkg/icingadb/schema.go index aa4735af3..9aa7374e9 100644 --- a/pkg/icingadb/schema.go +++ b/pkg/icingadb/schema.go @@ -11,8 +11,8 @@ import ( ) const ( - expectedMysqlSchemaVersion = 5 - expectedPostgresSchemaVersion = 3 + expectedMysqlSchemaVersion = 6 + expectedPostgresSchemaVersion = 4 ) // CheckSchema asserts the database schema of the expected version being present. diff --git a/schema/mysql/schema.sql b/schema/mysql/schema.sql index 745a5e620..af95ef0fb 100644 --- a/schema/mysql/schema.sql +++ b/schema/mysql/schema.sql @@ -208,7 +208,7 @@ CREATE TABLE host ( notes_url_id binary(20) DEFAULT NULL COMMENT 'notes_url.id', notes text NOT NULL, icon_image_id binary(20) DEFAULT NULL COMMENT 'icon_image.id', - icon_image_alt varchar(32) NOT NULL, + icon_image_alt text NOT NULL, zone_name varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL COMMENT 'zone.name', zone_id binary(20) DEFAULT NULL COMMENT 'zone.id', @@ -376,7 +376,7 @@ CREATE TABLE service ( notes_url_id binary(20) DEFAULT NULL COMMENT 'notes_url.id', notes text NOT NULL, icon_image_id binary(20) DEFAULT NULL COMMENT 'icon_image.id', - icon_image_alt varchar(32) NOT NULL, + icon_image_alt text NOT NULL, zone_name varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL COMMENT 'zone.name', zone_id binary(20) DEFAULT NULL COMMENT 'zone.id', @@ -506,7 +506,7 @@ CREATE TABLE endpoint ( id binary(20) NOT NULL COMMENT 'sha1(environment.id + name)', environment_id binary(20) NOT NULL COMMENT 'environment.id', name_checksum binary(20) NOT NULL COMMENT 'sha1(name)', - properties_checksum binary(20) NOT NULL, + properties_checksum binary(20) NOT NULL COMMENT 'sha1(all properties)', name varchar(255) NOT NULL, name_ci varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL, @@ -739,7 +739,7 @@ CREATE TABLE comment ( service_id binary(20) DEFAULT NULL COMMENT 'service.id', name_checksum binary(20) NOT NULL COMMENT 'sha1(name)', - properties_checksum binary(20) NOT NULL, + properties_checksum binary(20) NOT NULL COMMENT 'sha1(all properties)', name varchar(548) NOT NULL COMMENT '255+1+255+1+36, i.e. "host.name!service.name!UUID"', author varchar(255) NOT NULL COLLATE utf8mb4_unicode_ci, @@ -808,7 +808,7 @@ CREATE TABLE notification ( id binary(20) NOT NULL COMMENT 'sha1(environment.id + name)', environment_id binary(20) NOT NULL COMMENT 'environment.id', name_checksum binary(20) NOT NULL COMMENT 'sha1(name)', - properties_checksum binary(20) NOT NULL, + properties_checksum binary(20) NOT NULL COMMENT 'sha1(all properties)', name varchar(767) NOT NULL COMMENT '255+1+255+1+255, i.e. "host.name!service.name!notification.name"', name_ci varchar(767) COLLATE utf8mb4_unicode_ci NOT NULL, @@ -934,7 +934,7 @@ CREATE TABLE timeperiod_range ( timeperiod_id binary(20) NOT NULL COMMENT 'timeperiod.id', range_key varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL, - range_value varchar(255) NOT NULL, + range_value text NOT NULL, PRIMARY KEY (id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin ROW_FORMAT=DYNAMIC; diff --git a/schema/mysql/upgrades/1.2.1.sql b/schema/mysql/upgrades/1.2.1.sql new file mode 100644 index 000000000..ed86c6e72 --- /dev/null +++ b/schema/mysql/upgrades/1.2.1.sql @@ -0,0 +1,11 @@ +ALTER TABLE host MODIFY COLUMN icon_image_alt TEXT NOT NULL; +ALTER TABLE service MODIFY COLUMN icon_image_alt TEXT NOT NULL; + +ALTER TABLE endpoint MODIFY COLUMN properties_checksum binary(20) NOT NULL COMMENT 'sha1(all properties)'; +ALTER TABLE comment MODIFY COLUMN properties_checksum binary(20) NOT NULL COMMENT 'sha1(all properties)'; +ALTER TABLE notification MODIFY COLUMN properties_checksum binary(20) NOT NULL COMMENT 'sha1(all properties)'; + +ALTER TABLE timeperiod_range MODIFY COLUMN range_value text NOT NULL; + +INSERT INTO icingadb_schema (version, timestamp) + VALUES (6, UNIX_TIMESTAMP() * 1000); diff --git a/schema/pgsql/schema.sql b/schema/pgsql/schema.sql index 708c9143c..dc582fb66 100644 --- a/schema/pgsql/schema.sql +++ b/schema/pgsql/schema.sql @@ -235,7 +235,7 @@ CREATE TABLE host ( notes_url_id bytea20 DEFAULT NULL, notes text NOT NULL, icon_image_id bytea20 DEFAULT NULL, - icon_image_alt varchar(32) NOT NULL, + icon_image_alt text NOT NULL, zone_name citext NOT NULL, zone_id bytea20 DEFAULT NULL, @@ -509,7 +509,7 @@ CREATE TABLE service ( notes_url_id bytea20 DEFAULT NULL, notes text NOT NULL, icon_image_id bytea20 DEFAULT NULL, - icon_image_alt varchar(32) NOT NULL, + icon_image_alt text NOT NULL, zone_name citext NOT NULL, zone_id bytea20 DEFAULT NULL, @@ -761,6 +761,7 @@ ALTER TABLE endpoint ALTER COLUMN zone_id SET STORAGE PLAIN; COMMENT ON COLUMN endpoint.id IS 'sha1(environment.id + name)'; COMMENT ON COLUMN endpoint.environment_id IS 'environment.id'; COMMENT ON COLUMN endpoint.name_checksum IS 'sha1(name)'; +COMMENT ON COLUMN endpoint.properties_checksum IS 'sha1(all properties)'; COMMENT ON COLUMN endpoint.zone_id IS 'zone.id'; CREATE TABLE environment ( @@ -1159,6 +1160,7 @@ COMMENT ON COLUMN comment.environment_id IS 'environment.id'; COMMENT ON COLUMN comment.host_id IS 'host.id'; COMMENT ON COLUMN comment.service_id IS 'service.id'; COMMENT ON COLUMN comment.name_checksum IS 'sha1(name)'; +COMMENT ON COLUMN comment.properties_checksum IS 'sha1(all properties)'; COMMENT ON COLUMN comment.name IS '255+1+255+1+36, i.e. "host.name!service.name!UUID"'; COMMENT ON COLUMN comment.zone_id IS 'zone.id'; @@ -1288,6 +1290,7 @@ CREATE INDEX idx_notification_service_id ON notification(service_id); COMMENT ON COLUMN notification.id IS 'sha1(environment.id + name)'; COMMENT ON COLUMN notification.environment_id IS 'environment.id'; COMMENT ON COLUMN notification.name_checksum IS 'sha1(name)'; +COMMENT ON COLUMN notification.properties_checksum IS 'sha1(all properties)'; COMMENT ON COLUMN notification.name IS '255+1+255+1+255, i.e. "host.name!service.name!notification.name"'; COMMENT ON COLUMN notification.host_id IS 'host.id'; COMMENT ON COLUMN notification.service_id IS 'service.id'; @@ -1471,7 +1474,7 @@ CREATE TABLE timeperiod_range ( timeperiod_id bytea20 NOT NULL, range_key citext NOT NULL, - range_value varchar(255) NOT NULL, + range_value text NOT NULL, CONSTRAINT pk_timeperiod_range PRIMARY KEY (id) ); diff --git a/schema/pgsql/upgrades/1.2.1.sql b/schema/pgsql/upgrades/1.2.1.sql new file mode 100644 index 000000000..5989e3a77 --- /dev/null +++ b/schema/pgsql/upgrades/1.2.1.sql @@ -0,0 +1,11 @@ +ALTER TABLE host ALTER COLUMN icon_image_alt TYPE text; +ALTER TABLE service ALTER COLUMN icon_image_alt TYPE text; + +COMMENT ON COLUMN endpoint.properties_checksum IS 'sha1(all properties)'; +COMMENT ON COLUMN comment.properties_checksum IS 'sha1(all properties)'; +COMMENT ON COLUMN notification.properties_checksum IS 'sha1(all properties)'; + +ALTER TABLE timeperiod_range ALTER COLUMN range_value TYPE text; + +INSERT INTO icingadb_schema (version, timestamp) + VALUES (4, extract(epoch from now()) * 1000);