PlanTempusApp/Database/ConfigurationManagementSystem/SetupConfiguration.cs

181 lines
7.7 KiB
C#
Raw Normal View History

2025-01-26 22:57:27 +01:00
using Insight.Database;
using PlanTempus.Database.Core;
2025-01-26 22:57:27 +01:00
using System.Data;
namespace PlanTempus.Database.ConfigurationManagementSystem;
2025-01-26 22:57:27 +01:00
public class SetupConfiguration : IDbConfigure<SetupConfiguration.Command>
2025-01-26 22:57:27 +01:00
{
public class Command
{
}
private readonly IDbConnection _db;
public SetupConfiguration(IDbConnection connection)
{
_db = connection;
}
public void With(Command notInUse)
{
using (var transaction = _db.OpenWithTransaction())
{
try
{
CreateConfigurationTable();
CreateHistoryTable();
CreateConfigurationIndexes();
CreateModifiedAtTrigger();
CreateNotifyTrigger();
CreateHistoryTrigger();
transaction.Commit();
}
catch (Exception ex)
{
transaction.Rollback();
throw new InvalidOperationException("Failed to SetupConfiguration in Database", ex);
}
}
}
private void ExecuteSql(string sql)
{
_db.ExecuteSql(sql);
}
void CreateConfigurationTable()
{
const string sql = @"
2025-02-13 17:06:22 +01:00
CREATE TABLE IF NOT EXISTS app_configuration (
2025-01-26 22:57:27 +01:00
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)
);";
ExecuteSql(sql);
}
2025-01-26 22:57:27 +01:00
void CreateHistoryTable()
{
const string sql = @"
2025-02-13 17:06:22 +01:00
CREATE TABLE IF NOT EXISTS app_configuration_history (
2025-01-26 22:57:27 +01:00
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)
);";
ExecuteSql(sql);
}
2025-01-26 22:57:27 +01:00
void CreateConfigurationIndexes()
{
const string sql = @"
2025-02-14 20:14:01 +01:00
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);";
ExecuteSql(sql);
}
2025-01-26 22:57:27 +01:00
void CreateModifiedAtTrigger()
{
const string sql = @"
2025-01-28 14:51:09 +01:00
CREATE OR REPLACE FUNCTION update_app_configuration_modified_at()
2025-01-26 22:57:27 +01:00
RETURNS TRIGGER AS $$
BEGIN
NEW.modified_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
2025-02-14 20:14:01 +01:00
CREATE OR REPLACE TRIGGER trg_app_configuration_modified_at
2025-01-28 14:51:09 +01:00
BEFORE UPDATE ON app_configuration
2025-01-26 22:57:27 +01:00
FOR EACH ROW
2025-01-28 14:51:09 +01:00
EXECUTE FUNCTION update_app_configuration_modified_at();";
ExecuteSql(sql);
}
2025-01-26 22:57:27 +01:00
void CreateNotifyTrigger()
{
const string sql = @"
2025-01-28 14:51:09 +01:00
CREATE OR REPLACE FUNCTION notify_app_configuration_change()
2025-01-26 22:57:27 +01:00
RETURNS TRIGGER AS $$
BEGIN
PERFORM pg_notify('config_changes', NEW.key);
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
2025-02-14 20:14:01 +01:00
CREATE OR REPLACE TRIGGER trg_app_configuration_notify
2025-01-28 14:51:09 +01:00
AFTER INSERT OR UPDATE ON app_configuration
2025-01-26 22:57:27 +01:00
FOR EACH ROW
2025-01-28 14:51:09 +01:00
EXECUTE FUNCTION notify_app_configuration_change();";
ExecuteSql(sql);
}
2025-01-26 22:57:27 +01:00
void CreateHistoryTrigger()
{
const string sql = @"
2025-01-28 14:51:09 +01:00
CREATE OR REPLACE FUNCTION log_app_configuration_changes()
2025-01-26 22:57:27 +01:00
RETURNS TRIGGER AS $$
BEGIN
IF (TG_OP = 'INSERT') THEN
2025-01-28 14:51:09 +01:00
INSERT INTO app_configuration_history (
2025-01-26 22:57:27 +01:00
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
2025-01-28 14:51:09 +01:00
INSERT INTO app_configuration_history (
2025-01-26 22:57:27 +01:00
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
2025-01-28 14:51:09 +01:00
INSERT INTO app_configuration_history (
2025-01-26 22:57:27 +01:00
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;
2025-02-14 20:14:01 +01:00
CREATE OR REPLACE TRIGGER trg_app_configuration_history
2025-01-28 14:51:09 +01:00
AFTER INSERT OR UPDATE OR DELETE ON app_configuration
FOR EACH ROW EXECUTE FUNCTION log_app_configuration_changes();";
ExecuteSql(sql);
}
2025-01-26 22:57:27 +01:00
2025-01-28 14:51:09 +01:00
2025-01-26 22:57:27 +01:00
}