using System; using System.Data; using System.Threading.Tasks; namespace Database.Tenants { public class DbSetup { private readonly IDbConnection _db; public DbSetup(IDbConnection db) { _db = db ?? throw new ArgumentNullException(nameof(db)); } /// /// Creates the users table in the ptmain schema. /// public void CreateUsersTable() { ExecuteInTransaction(@" 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 );"); } /// /// Creates the tenants table in the ptmain schema. /// public void CreateTenantsTable() { ExecuteInTransaction(@" 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 );"); } /// /// Creates the user_tenants table in the ptmain schema. /// public void CreateUserTenantsTable() { ExecuteInTransaction(@" 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) );"); } /// /// Sets up Row Level Security (RLS) for the tenants and user_tenants tables. /// public void SetupRLS() { ExecuteInTransaction( "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);" ); } /// /// Executes one or more SQL commands within a transaction. /// /// The SQL commands to execute. private void ExecuteInTransaction(params string[] sqlCommands) { if (_db.State != ConnectionState.Open) _db.Open(); using var transaction = _db.BeginTransaction(); try { foreach (var sql in sqlCommands) { _db.ExecuteSql(sql, transaction: transaction); } transaction.Commit(); } catch (Exception ex) { transaction.Rollback(); throw new InvalidOperationException("Failed to execute SQL commands in transaction.", ex); } } } }