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