using Database.Common; using Insight.Database; using System; using System.Data; using System.Threading.Tasks; namespace Database.IdentitySystem { public class DbSetup { readonly IDbConnection _db; IDbTransaction _transaction = null; string _schema; public DbSetup(IDbConnection db) { _db = db ?? throw new ArgumentNullException(nameof(db)); } /// /// Creates the system tables in the specified schema within a transaction. /// /// The schema name where the tables will be created. public async Task CreateSystem(string schema) { _schema = schema; if (!Validations.IsValidSchemaName(schema)) throw new ArgumentException("Invalid schema name", nameof(schema)); using (_transaction = _db.BeginTransaction()) { try { await CreateUsersTable().ConfigureAwait(false); await CreateTenantsTable().ConfigureAwait(false); await CreateUserTenantsTable().ConfigureAwait(false); await SetupRLS().ConfigureAwait(false); _transaction.Commit(); } catch (Exception ex) { _transaction.Rollback(); throw new InvalidOperationException("Failed to create system tables.", ex); } } } private async Task ExecuteSqlAsync(string sql) { if (string.IsNullOrEmpty(sql)) throw new ArgumentNullException(nameof(sql)); await _db.ExecuteAsync(sql).ConfigureAwait(false); } /// /// Creates the users table in the ptmain schema. /// public async Task CreateUsersTable() { var sql = @" CREATE TABLE IF NOT EXISTS ptmain.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 );"; await ExecuteSqlAsync(sql).ConfigureAwait(false); } /// /// Creates the tenants table in the ptmain schema. /// public async Task CreateTenantsTable() { var sql = @" CREATE TABLE IF NOT EXISTS ptmain.tenants ( id SERIAL PRIMARY KEY, connection_string VARCHAR(500) NOT NULL, is_active BOOLEAN NOT NULL DEFAULT TRUE, created_by INTEGER NOT NULL REFERENCES ptmain.users(id), created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP );"; await ExecuteSqlAsync(sql).ConfigureAwait(false); } /// /// Creates the user_tenants table in the ptmain schema. /// public async Task CreateUserTenantsTable() { var sql = @" CREATE TABLE IF NOT EXISTS ptmain.user_tenants ( user_id INTEGER NOT NULL REFERENCES ptmain.users(id), tenant_id INTEGER NOT NULL REFERENCES ptmain.tenants(id), pin_code VARCHAR(10) NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (user_id, tenant_id) );"; await ExecuteSqlAsync(sql).ConfigureAwait(false); } /// /// Sets up Row Level Security (RLS) for the tenants and user_tenants tables. /// public async Task SetupRLS() { var sql = new[] { "ALTER TABLE ptmain.tenants ENABLE ROW LEVEL SECURITY;", "ALTER TABLE ptmain.user_tenants ENABLE ROW LEVEL SECURITY;", "DROP POLICY IF EXISTS tenant_access ON ptmain.tenants;", @"CREATE POLICY tenant_access ON ptmain.tenants USING (id IN ( SELECT tenant_id FROM ptmain.user_tenants WHERE user_id = current_setting('app.user_id', TRUE)::INTEGER ));", "DROP POLICY IF EXISTS user_tenant_access ON ptmain.user_tenants;", @"CREATE POLICY user_tenant_access ON ptmain.user_tenants USING (user_id = current_setting('app.user_id', TRUE)::INTEGER);" }; foreach (var statement in sql) { await ExecuteSqlAsync(statement).ConfigureAwait(false); } } } }