Skip to content

Commit

Permalink
schema: Fix values to fit by increasing type sizes
Browse files Browse the repository at this point in the history
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.
  • Loading branch information
oxzi committed Jul 29, 2024
1 parent b2203b9 commit af52e88
Show file tree
Hide file tree
Showing 5 changed files with 38 additions and 13 deletions.
4 changes: 2 additions & 2 deletions pkg/icingadb/schema.go
Original file line number Diff line number Diff line change
Expand Up @@ -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.
Expand Down
14 changes: 7 additions & 7 deletions schema/mysql/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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',
Expand Down Expand Up @@ -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',
Expand Down Expand Up @@ -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,
Expand Down Expand Up @@ -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,
Expand Down Expand Up @@ -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,
Expand Down Expand Up @@ -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;
Expand Down Expand Up @@ -1343,4 +1343,4 @@ CREATE TABLE icingadb_schema (
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin ROW_FORMAT=DYNAMIC;

INSERT INTO icingadb_schema (version, timestamp)
VALUES (5, UNIX_TIMESTAMP() * 1000);
VALUES (6, UNIX_TIMESTAMP() * 1000);
11 changes: 11 additions & 0 deletions schema/mysql/upgrades/1.2.1.sql
Original file line number Diff line number Diff line change
@@ -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);
11 changes: 7 additions & 4 deletions schema/pgsql/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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,
Expand Down Expand Up @@ -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,
Expand Down Expand Up @@ -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 (
Expand Down Expand Up @@ -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';

Expand Down Expand Up @@ -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';
Expand Down Expand Up @@ -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)
);
Expand Down Expand Up @@ -2181,4 +2184,4 @@ CREATE TABLE icingadb_schema (
ALTER SEQUENCE icingadb_schema_id_seq OWNED BY icingadb_schema.id;

INSERT INTO icingadb_schema (version, timestamp)
VALUES (3, extract(epoch from now()) * 1000);
VALUES (4, extract(epoch from now()) * 1000);
11 changes: 11 additions & 0 deletions schema/pgsql/upgrades/1.2.1.sql
Original file line number Diff line number Diff line change
@@ -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);

0 comments on commit af52e88

Please sign in to comment.