using Insight.Database; using PlanTempus.Database.Core; using PlanTempus.Database.Core.ConnectionFactory; using System.Data; namespace PlanTempus.Database.ConfigurationManagementSystem; public class SetupConfiguration : IDbConfigure { public class Command { } private readonly IDbConnectionFactory _connectionFactory; public SetupConfiguration(IDbConnectionFactory connectionFactory) { _connectionFactory = connectionFactory; } public void With(Command notInUse) { using var conn = _connectionFactory.Create(); using var transaction = conn.OpenWithTransaction(); try { CreateConfigurationTable(conn); CreateHistoryTable(conn); CreateConfigurationIndexes(conn); CreateModifiedAtTrigger(conn); CreateNotifyTrigger(conn); CreateHistoryTrigger(conn); transaction.Commit(); } catch (Exception ex) { transaction.Rollback(); throw new InvalidOperationException("Failed to SetupConfiguration in Database", ex); } } void CreateConfigurationTable(IDbConnection db) { const string sql = @" CREATE TABLE IF NOT EXISTS app_configuration ( id bigserial NOT NULL, ""key"" varchar(255) NOT NULL, value text NULL, ""label"" varchar(255) NULL, content_type varchar(255) DEFAULT 'text/plain'::character varying NULL, valid_from timestamptz NULL, expires_at timestamptz NULL, created_at timestamptz DEFAULT CURRENT_TIMESTAMP NULL, modified_at timestamptz DEFAULT CURRENT_TIMESTAMP NULL, etag uuid DEFAULT gen_random_uuid() NULL, CONSTRAINT app_configuration_pkey PRIMARY KEY (id) );"; db.ExecuteSql(sql); } void CreateHistoryTable(IDbConnection db) { const string sql = @" CREATE TABLE IF NOT EXISTS app_configuration_history ( history_id bigserial NOT NULL, action_type char(1) NOT NULL, action_timestamp timestamptz NOT NULL DEFAULT CURRENT_TIMESTAMP, action_by text NOT NULL DEFAULT CURRENT_USER, id bigint NOT NULL, ""key"" varchar(255) NOT NULL, value text NULL, ""label"" varchar(255) NULL, content_type varchar(255) NULL, valid_from timestamptz NULL, expires_at timestamptz NULL, created_at timestamptz NULL, modified_at timestamptz NULL, etag uuid NULL, CONSTRAINT app_configuration_history_pkey PRIMARY KEY (history_id) );"; db.ExecuteSql(sql); } void CreateConfigurationIndexes(IDbConnection db) { const string sql = @" CREATE INDEX IF NOT EXISTS idx_app_configuration_key ON app_configuration(""key""); CREATE INDEX IF NOT EXISTS idx_app_configuration_validity ON app_configuration(valid_from, expires_at);"; db.ExecuteSql(sql); } void CreateModifiedAtTrigger(IDbConnection db) { const string sql = @" CREATE OR REPLACE FUNCTION update_app_configuration_modified_at() RETURNS TRIGGER AS $$ BEGIN NEW.modified_at = CURRENT_TIMESTAMP; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE TRIGGER trg_app_configuration_modified_at BEFORE UPDATE ON app_configuration FOR EACH ROW EXECUTE FUNCTION update_app_configuration_modified_at();"; db.ExecuteSql(sql); } void CreateNotifyTrigger(IDbConnection db) { const string sql = @" CREATE OR REPLACE FUNCTION notify_app_configuration_change() RETURNS TRIGGER AS $$ BEGIN PERFORM pg_notify('config_changes', NEW.key); RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE TRIGGER trg_app_configuration_notify AFTER INSERT OR UPDATE ON app_configuration FOR EACH ROW EXECUTE FUNCTION notify_app_configuration_change();"; db.ExecuteSql(sql); } void CreateHistoryTrigger(IDbConnection db) { const string sql = @" CREATE OR REPLACE FUNCTION log_app_configuration_changes() RETURNS TRIGGER AS $$ BEGIN IF (TG_OP = 'INSERT') THEN INSERT INTO app_configuration_history ( action_type, id, ""key"", value, label, content_type, valid_from, expires_at, created_at, modified_at, etag ) VALUES ( 'I', NEW.id, NEW.key, NEW.value, NEW.label, NEW.content_type, NEW.valid_from, NEW.expires_at, NEW.created_at, NEW.modified_at, NEW.etag ); ELSIF (TG_OP = 'UPDATE') THEN INSERT INTO app_configuration_history ( action_type, id, ""key"", value, label, content_type, valid_from, expires_at, created_at, modified_at, etag ) VALUES ( 'U', OLD.id, OLD.key, OLD.value, OLD.label, OLD.content_type, OLD.valid_from, OLD.expires_at, OLD.created_at, OLD.modified_at, OLD.etag ); ELSIF (TG_OP = 'DELETE') THEN INSERT INTO app_configuration_history ( action_type, id, ""key"", value, label, content_type, valid_from, expires_at, created_at, modified_at, etag ) VALUES ( 'D', OLD.id, OLD.key, OLD.value, OLD.label, OLD.content_type, OLD.valid_from, OLD.expires_at, OLD.created_at, OLD.modified_at, OLD.etag ); END IF; RETURN NULL; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE TRIGGER trg_app_configuration_history AFTER INSERT OR UPDATE OR DELETE ON app_configuration FOR EACH ROW EXECUTE FUNCTION log_app_configuration_changes();"; db.ExecuteSql(sql); } }