From 658c4671500727cf5b2fc8903c918e0149b8abd6 Mon Sep 17 00:00:00 2001 From: Sukhwinder Dhillon Date: Tue, 11 Jun 2024 10:27:47 +0200 Subject: [PATCH 1/3] Add column `external_uuid` to `contact/contactgroup/channel` table --- schema/pgsql/schema.sql | 11 +++++++++-- schema/pgsql/upgrades/0.2.0-external-uuid.sql | 15 +++++++++++++++ 2 files changed, 24 insertions(+), 2 deletions(-) create mode 100644 schema/pgsql/upgrades/0.2.0-external-uuid.sql diff --git a/schema/pgsql/schema.sql b/schema/pgsql/schema.sql index 5ddb12e7..0563d4aa 100644 --- a/schema/pgsql/schema.sql +++ b/schema/pgsql/schema.sql @@ -47,12 +47,14 @@ CREATE TABLE channel ( config text, -- JSON with channel-specific attributes -- for now type determines the implementation, in the future, this will need a reference to a concrete -- implementation to allow multiple implementations of a sms channel for example, probably even user-provided ones + external_uuid uuid NOT NULL, changed_at bigint NOT NULL, deleted boolenum NOT NULL DEFAULT 'n', CONSTRAINT pk_channel PRIMARY KEY (id), - CONSTRAINT fk_channel_available_channel_type FOREIGN KEY (type) REFERENCES available_channel_type(type) + CONSTRAINT fk_channel_available_channel_type FOREIGN KEY (type) REFERENCES available_channel_type(type), + UNIQUE (external_uuid) ); CREATE INDEX idx_channel_changed_at ON channel(changed_at); @@ -62,11 +64,14 @@ CREATE TABLE contact ( full_name citext NOT NULL, username citext, -- reference to web user default_channel_id bigint NOT NULL, + external_uuid uuid NOT NULL, changed_at bigint NOT NULL, deleted boolenum NOT NULL DEFAULT 'n', CONSTRAINT pk_contact PRIMARY KEY (id), + UNIQUE (username), + UNIQUE (external_uuid), -- As the username is unique, it must be NULLed for deletion via "deleted = 'y'" CONSTRAINT uk_contact_username UNIQUE (username), @@ -95,11 +100,13 @@ CREATE INDEX idx_contact_address_changed_at ON contact_address(changed_at); CREATE TABLE contactgroup ( id bigserial, name citext NOT NULL, + external_uuid uuid NOT NULL, changed_at bigint NOT NULL, deleted boolenum NOT NULL DEFAULT 'n', - CONSTRAINT pk_contactgroup PRIMARY KEY (id) + CONSTRAINT pk_contactgroup PRIMARY KEY (id), + UNIQUE (external_uuid) ); CREATE INDEX idx_contactgroup_changed_at ON contactgroup(changed_at); diff --git a/schema/pgsql/upgrades/0.2.0-external-uuid.sql b/schema/pgsql/upgrades/0.2.0-external-uuid.sql new file mode 100644 index 00000000..b8ef5f85 --- /dev/null +++ b/schema/pgsql/upgrades/0.2.0-external-uuid.sql @@ -0,0 +1,15 @@ +CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; + +ALTER TABLE contact ADD COLUMN external_uuid uuid UNIQUE; +ALTER TABLE contactgroup ADD COLUMN external_uuid uuid UNIQUE; +ALTER TABLE channel ADD COLUMN external_uuid uuid UNIQUE; + +UPDATE contact SET external_uuid = uuid_generate_v4() WHERE external_uuid IS NULL; +UPDATE contactgroup SET external_uuid = uuid_generate_v4() WHERE external_uuid IS NULL; +UPDATE channel SET external_uuid = uuid_generate_v4() WHERE external_uuid IS NULL; + +ALTER TABLE contact ALTER COLUMN external_uuid SET NOT NULL; +ALTER TABLE contactgroup ALTER COLUMN external_uuid SET NOT NULL; +ALTER TABLE channel ALTER COLUMN external_uuid SET NOT NULL; + +DROP EXTENSION "uuid-ossp"; From e3f06c956e317c819bb188cb844799b271d27c09 Mon Sep 17 00:00:00 2001 From: Johannes Meyer Date: Wed, 22 Oct 2025 13:51:42 +0200 Subject: [PATCH 2/3] pgsql: Conform to current schema definition --- schema/pgsql/schema.sql | 15 +++++++-------- schema/pgsql/upgrades/0.2.0-external-uuid.sql | 6 +++--- 2 files changed, 10 insertions(+), 11 deletions(-) diff --git a/schema/pgsql/schema.sql b/schema/pgsql/schema.sql index 0563d4aa..3f2d943c 100644 --- a/schema/pgsql/schema.sql +++ b/schema/pgsql/schema.sql @@ -42,36 +42,35 @@ CREATE TABLE available_channel_type ( CREATE TABLE channel ( id bigserial, + external_uuid uuid NOT NULL, -- used for external references name citext NOT NULL, type varchar(255) NOT NULL, -- 'email', 'sms', ... config text, -- JSON with channel-specific attributes -- for now type determines the implementation, in the future, this will need a reference to a concrete -- implementation to allow multiple implementations of a sms channel for example, probably even user-provided ones - external_uuid uuid NOT NULL, changed_at bigint NOT NULL, deleted boolenum NOT NULL DEFAULT 'n', CONSTRAINT pk_channel PRIMARY KEY (id), - CONSTRAINT fk_channel_available_channel_type FOREIGN KEY (type) REFERENCES available_channel_type(type), - UNIQUE (external_uuid) + CONSTRAINT uk_channel_external_uuid UNIQUE (external_uuid), + CONSTRAINT fk_channel_available_channel_type FOREIGN KEY (type) REFERENCES available_channel_type(type) ); CREATE INDEX idx_channel_changed_at ON channel(changed_at); CREATE TABLE contact ( id bigserial, + external_uuid uuid NOT NULL, -- used for external references full_name citext NOT NULL, username citext, -- reference to web user default_channel_id bigint NOT NULL, - external_uuid uuid NOT NULL, changed_at bigint NOT NULL, deleted boolenum NOT NULL DEFAULT 'n', CONSTRAINT pk_contact PRIMARY KEY (id), - UNIQUE (username), - UNIQUE (external_uuid), + CONSTRAINT uk_contact_external_uuid UNIQUE (external_uuid), -- As the username is unique, it must be NULLed for deletion via "deleted = 'y'" CONSTRAINT uk_contact_username UNIQUE (username), @@ -99,14 +98,14 @@ CREATE INDEX idx_contact_address_changed_at ON contact_address(changed_at); CREATE TABLE contactgroup ( id bigserial, + external_uuid uuid NOT NULL, -- used for external references name citext NOT NULL, - external_uuid uuid NOT NULL, changed_at bigint NOT NULL, deleted boolenum NOT NULL DEFAULT 'n', CONSTRAINT pk_contactgroup PRIMARY KEY (id), - UNIQUE (external_uuid) + CONSTRAINT uk_contactgroup_external_uuid UNIQUE (external_uuid) ); CREATE INDEX idx_contactgroup_changed_at ON contactgroup(changed_at); diff --git a/schema/pgsql/upgrades/0.2.0-external-uuid.sql b/schema/pgsql/upgrades/0.2.0-external-uuid.sql index b8ef5f85..a79192cf 100644 --- a/schema/pgsql/upgrades/0.2.0-external-uuid.sql +++ b/schema/pgsql/upgrades/0.2.0-external-uuid.sql @@ -1,8 +1,8 @@ CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -ALTER TABLE contact ADD COLUMN external_uuid uuid UNIQUE; -ALTER TABLE contactgroup ADD COLUMN external_uuid uuid UNIQUE; -ALTER TABLE channel ADD COLUMN external_uuid uuid UNIQUE; +ALTER TABLE contact ADD COLUMN external_uuid uuid CONSTRAINT uk_contact_external_uuid UNIQUE; +ALTER TABLE contactgroup ADD COLUMN external_uuid uuid CONSTRAINT uk_contactgroup_external_uuid UNIQUE; +ALTER TABLE channel ADD COLUMN external_uuid uuid CONSTRAINT uk_channel_external_uuid UNIQUE; UPDATE contact SET external_uuid = uuid_generate_v4() WHERE external_uuid IS NULL; UPDATE contactgroup SET external_uuid = uuid_generate_v4() WHERE external_uuid IS NULL; From 9edddb59cb406a92a979b01ba9bf00e1316f51c8 Mon Sep 17 00:00:00 2001 From: Johannes Meyer Date: Wed, 22 Oct 2025 13:52:52 +0200 Subject: [PATCH 3/3] mysql: Introduce `external_uuid` to `contact`, `contactgroup` and `channel` The `UUID()` function exists since MySQL 8.0 and is available in MariaDB 10.2.2. Both current minimum requirements for Icinga DB. --- schema/mysql/schema.sql | 8 +++++++- schema/mysql/upgrades/0.2.0-external-uuid.sql | 15 +++++++++++++++ 2 files changed, 22 insertions(+), 1 deletion(-) create mode 100644 schema/mysql/upgrades/0.2.0-external-uuid.sql diff --git a/schema/mysql/schema.sql b/schema/mysql/schema.sql index 27f1ef5c..3f4f2889 100644 --- a/schema/mysql/schema.sql +++ b/schema/mysql/schema.sql @@ -10,6 +10,7 @@ CREATE TABLE available_channel_type ( CREATE TABLE channel ( id bigint NOT NULL AUTO_INCREMENT, + external_uuid char(36) NOT NULL, -- used for external references, lower case name text NOT NULL COLLATE utf8mb4_unicode_ci, type varchar(255) NOT NULL, -- 'email', 'sms', ... config mediumtext, -- JSON with channel-specific attributes @@ -20,6 +21,7 @@ CREATE TABLE channel ( deleted enum('n', 'y') NOT NULL DEFAULT 'n', CONSTRAINT pk_channel PRIMARY KEY (id), + CONSTRAINT uk_channel_external_uuid UNIQUE (external_uuid), CONSTRAINT fk_channel_available_channel_type FOREIGN KEY (type) REFERENCES available_channel_type(type) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; @@ -27,6 +29,7 @@ CREATE INDEX idx_channel_changed_at ON channel(changed_at); CREATE TABLE contact ( id bigint NOT NULL AUTO_INCREMENT, + external_uuid char(36) NOT NULL, -- used for external references, lower case full_name text NOT NULL COLLATE utf8mb4_unicode_ci, username varchar(254) COLLATE utf8mb4_unicode_ci, -- reference to web user default_channel_id bigint NOT NULL, @@ -35,6 +38,7 @@ CREATE TABLE contact ( deleted enum('n', 'y') NOT NULL DEFAULT 'n', CONSTRAINT pk_contact PRIMARY KEY (id), + CONSTRAINT uk_contact_external_uuid UNIQUE (external_uuid), -- As the username is unique, it must be NULLed for deletion via "deleted = 'y'" CONSTRAINT uk_contact_username UNIQUE (username), @@ -61,12 +65,14 @@ CREATE INDEX idx_contact_address_changed_at ON contact_address(changed_at); CREATE TABLE contactgroup ( id bigint NOT NULL AUTO_INCREMENT, + external_uuid char(36) NOT NULL, -- used for external references, lower case name text NOT NULL COLLATE utf8mb4_unicode_ci, changed_at bigint NOT NULL, deleted enum('n', 'y') NOT NULL DEFAULT 'n', - CONSTRAINT pk_contactgroup PRIMARY KEY (id) + CONSTRAINT pk_contactgroup PRIMARY KEY (id), + CONSTRAINT uk_contactgroup_external_uuid UNIQUE (external_uuid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; CREATE INDEX idx_contactgroup_changed_at ON contactgroup(changed_at); diff --git a/schema/mysql/upgrades/0.2.0-external-uuid.sql b/schema/mysql/upgrades/0.2.0-external-uuid.sql new file mode 100644 index 00000000..750bdd4e --- /dev/null +++ b/schema/mysql/upgrades/0.2.0-external-uuid.sql @@ -0,0 +1,15 @@ +ALTER TABLE contact ADD COLUMN external_uuid char(36) AFTER id; +ALTER TABLE contactgroup ADD COLUMN external_uuid char(36) AFTER id; +ALTER TABLE channel ADD COLUMN external_uuid char(36) AFTER id; + +UPDATE contact SET external_uuid = UUID() WHERE external_uuid IS NULL; +UPDATE contactgroup SET external_uuid = UUID() WHERE external_uuid IS NULL; +UPDATE channel SET external_uuid = UUID() WHERE external_uuid IS NULL; + +ALTER TABLE contact MODIFY COLUMN external_uuid char(36) NOT NULL; +ALTER TABLE contactgroup MODIFY COLUMN external_uuid char(36) NOT NULL; +ALTER TABLE channel MODIFY COLUMN external_uuid char(36) NOT NULL; + +ALTER TABLE contact ADD CONSTRAINT uk_contact_external_uuid UNIQUE (external_uuid); +ALTER TABLE contactgroup ADD CONSTRAINT uk_contactgroup_external_uuid UNIQUE (external_uuid); +ALTER TABLE channel ADD CONSTRAINT uk_channel_external_uuid UNIQUE (external_uuid);