155 lines
7.4 KiB
C#
155 lines
7.4 KiB
C#
|
|
using Insight.Database;
|
|||
|
|
using System.Data;
|
|||
|
|
|
|||
|
|
namespace Database.AppConfigurationSystem;
|
|||
|
|
|
|||
|
|
public class ConfigurationDatabaseSetup
|
|||
|
|
{
|
|||
|
|
private readonly IDbConnection _connection;
|
|||
|
|
|
|||
|
|
public ConfigurationDatabaseSetup(IDbConnection connection)
|
|||
|
|
{
|
|||
|
|
_connection = connection;
|
|||
|
|
}
|
|||
|
|
|
|||
|
|
public async Task CreateConfigurationTable()
|
|||
|
|
{
|
|||
|
|
const string sql = @"
|
|||
|
|
CREATE TABLE prod.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)
|
|||
|
|
);";
|
|||
|
|
await _connection.ExecuteAsync(sql);
|
|||
|
|
}
|
|||
|
|
|
|||
|
|
public async Task CreateHistoryTable()
|
|||
|
|
{
|
|||
|
|
const string sql = @"
|
|||
|
|
CREATE TABLE prod.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)
|
|||
|
|
);";
|
|||
|
|
await _connection.ExecuteAsync(sql);
|
|||
|
|
}
|
|||
|
|
|
|||
|
|
public async Task CreateConfigurationIndexes()
|
|||
|
|
{
|
|||
|
|
const string sql = @"
|
|||
|
|
CREATE INDEX idx_app_configuration_key ON prod.app_configuration(""key"");
|
|||
|
|
CREATE INDEX idx_app_configuration_validity ON prod.app_configuration(valid_from, expires_at);";
|
|||
|
|
await _connection.ExecuteAsync(sql);
|
|||
|
|
}
|
|||
|
|
|
|||
|
|
public async Task CreateModifiedAtTrigger()
|
|||
|
|
{
|
|||
|
|
const string sql = @"
|
|||
|
|
CREATE OR REPLACE FUNCTION prod.update_app_configuration_modified_at()
|
|||
|
|
RETURNS TRIGGER AS $$
|
|||
|
|
BEGIN
|
|||
|
|
NEW.modified_at = CURRENT_TIMESTAMP;
|
|||
|
|
RETURN NEW;
|
|||
|
|
END;
|
|||
|
|
$$ LANGUAGE plpgsql;
|
|||
|
|
|
|||
|
|
CREATE TRIGGER trg_app_configuration_modified_at
|
|||
|
|
BEFORE UPDATE ON prod.app_configuration
|
|||
|
|
FOR EACH ROW
|
|||
|
|
EXECUTE FUNCTION prod.update_app_configuration_modified_at();";
|
|||
|
|
await _connection.ExecuteAsync(sql);
|
|||
|
|
}
|
|||
|
|
|
|||
|
|
public async Task CreateNotifyTrigger()
|
|||
|
|
{
|
|||
|
|
const string sql = @"
|
|||
|
|
CREATE OR REPLACE FUNCTION prod.notify_app_configuration_change()
|
|||
|
|
RETURNS TRIGGER AS $$
|
|||
|
|
BEGIN
|
|||
|
|
PERFORM pg_notify('config_changes', NEW.key);
|
|||
|
|
RETURN NEW;
|
|||
|
|
END;
|
|||
|
|
$$ LANGUAGE plpgsql;
|
|||
|
|
|
|||
|
|
CREATE TRIGGER trg_app_configuration_notify
|
|||
|
|
AFTER INSERT OR UPDATE ON prod.app_configuration
|
|||
|
|
FOR EACH ROW
|
|||
|
|
EXECUTE FUNCTION prod.notify_app_configuration_change();";
|
|||
|
|
await _connection.ExecuteAsync(sql);
|
|||
|
|
}
|
|||
|
|
|
|||
|
|
public async Task CreateHistoryTrigger()
|
|||
|
|
{
|
|||
|
|
const string sql = @"
|
|||
|
|
CREATE OR REPLACE FUNCTION prod.log_app_configuration_changes()
|
|||
|
|
RETURNS TRIGGER AS $$
|
|||
|
|
BEGIN
|
|||
|
|
IF (TG_OP = 'INSERT') THEN
|
|||
|
|
INSERT INTO prod.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 prod.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 prod.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 TRIGGER trg_app_configuration_history
|
|||
|
|
AFTER INSERT OR UPDATE OR DELETE ON prod.app_configuration
|
|||
|
|
FOR EACH ROW EXECUTE FUNCTION prod.log_app_configuration_changes();";
|
|||
|
|
await _connection.ExecuteAsync(sql);
|
|||
|
|
}
|
|||
|
|
|
|||
|
|
public async Task CreateDatabaseStructure(IDbConnection connection)
|
|||
|
|
{
|
|||
|
|
await CreateConfigurationTable();
|
|||
|
|
await CreateHistoryTable();
|
|||
|
|
await CreateConfigurationIndexes();
|
|||
|
|
await CreateModifiedAtTrigger();
|
|||
|
|
await CreateNotifyTrigger();
|
|||
|
|
await CreateHistoryTrigger();
|
|||
|
|
}
|
|||
|
|
}
|