using Insight.Database; using System.Data; using PlanTempus.Core.Database.ConnectionFactory; namespace PlanTempus.Database.Core.DDL { /// /// This is by purpose not async await /// It is intended that this is created with the correct Application User, which is why the schema name is omitted. /// public class SetupIdentitySystem : IDbConfigure { public class Command { public required string Schema { get; init; } } Command _command; private readonly IDbConnectionFactory _connectionFactory; public SetupIdentitySystem(IDbConnectionFactory connectionFactory) { _connectionFactory = connectionFactory; } /// /// Creates the system tables in the specified schema within a transaction. /// /// The schema name where the tables will be created. public void With(Command command, ConnectionStringParameters parameters = null) { _command = command; using var conn = parameters is null ? _connectionFactory.Create() : _connectionFactory.Create(parameters); using var transaction = conn.OpenWithTransaction(); try { CreateUsersTable(conn); CreateOrganizationsTable(conn); CreateUserOrganizationsTable(conn); SetupRLS(conn); transaction.Commit(); } catch (Exception ex) { transaction.Rollback(); throw new InvalidOperationException("Failed to SetupIdentitySystem. Transaction is rolled back", ex); } } /// /// Creates the users table /// void CreateUsersTable(IDbConnection db) { var sql = @$" CREATE TABLE IF NOT EXISTS {_command.Schema}.users ( id SERIAL PRIMARY KEY, email VARCHAR(256) NOT NULL UNIQUE, password_hash VARCHAR(256) NOT NULL, security_stamp VARCHAR(36) NOT NULL, email_confirmed BOOLEAN NOT NULL DEFAULT FALSE, access_failed_count INTEGER NOT NULL DEFAULT 0, lockout_enabled BOOLEAN NOT NULL DEFAULT TRUE, lockout_end TIMESTAMPTZ NULL, is_active BOOLEAN NOT NULL DEFAULT TRUE, created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, last_login_at TIMESTAMPTZ NULL );"; db.ExecuteSql(sql); } /// /// Creates the organizations table /// void CreateOrganizationsTable(IDbConnection db) { var sql = @$" CREATE TABLE IF NOT EXISTS {_command.Schema}.organizations ( id SERIAL PRIMARY KEY, connection_string VARCHAR(500) NOT NULL, is_active BOOLEAN NOT NULL DEFAULT TRUE, created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP );"; db.ExecuteSql(sql); } /// /// Creates the user_organizations table /// void CreateUserOrganizationsTable(IDbConnection db) { var sql = @$" CREATE TABLE IF NOT EXISTS {_command.Schema}.user_organizations ( user_id INTEGER NOT NULL REFERENCES {_command.Schema}.users(id), organization_id INTEGER NOT NULL REFERENCES {_command.Schema}.organizations(id), pin_code VARCHAR(10) NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (user_id, organization_id) );"; db.ExecuteSql(sql); } /// /// Sets up Row Level Security (RLS) for the organizations and user_organizations tables. /// void SetupRLS(IDbConnection db) { var sql = new[] { $"ALTER TABLE {_command.Schema}.organizations ENABLE ROW LEVEL SECURITY;", $"ALTER TABLE {_command.Schema}.user_organizations ENABLE ROW LEVEL SECURITY;", $"DROP POLICY IF EXISTS organization_access ON {_command.Schema}.organizations;", @$"CREATE POLICY organization_access ON {_command.Schema}.organizations USING (id IN ( SELECT organization_id FROM {_command.Schema}.user_organizations WHERE user_id = current_setting('app.user_id', TRUE)::INTEGER )) WITH CHECK (true);", $"DROP POLICY IF EXISTS user_organization_access ON {_command.Schema}.user_organizations;", @$"CREATE POLICY user_organization_access ON {_command.Schema}.user_organizations USING (user_id = current_setting('app.user_id', TRUE)::INTEGER) WITH CHECK (true);" }; foreach (var statement in sql) { db.ExecuteSql(statement); } } } }