using Insight.Database; using System.Data; namespace 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 { } 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 With(Command emptyByIntention) { using (_transaction = _db.OpenWithTransaction()) { try { CreateUsersTable(); CreateOrganizationsTable(); CreateUserOrganizationsTable(); SetupRLS(); _transaction.Commit(); } catch (Exception ex) { _transaction.Rollback(); throw new InvalidOperationException("Failed to SetupIdentitySystem. Transaction is rolled back", ex); } } } private void ExecuteSql(string sql) { if (string.IsNullOrEmpty(sql)) throw new ArgumentNullException(nameof(sql)); _db.ExecuteSql(sql); } /// /// Creates the users table /// 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 organizations table /// void CreateOrganizationsTable() { var sql = @" CREATE TABLE IF NOT EXISTS organizations ( 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_organizations table /// void CreateUserOrganizationsTable() { var sql = @" CREATE TABLE IF NOT EXISTS user_organizations ( user_id INTEGER NOT NULL REFERENCES users(id), organization_id INTEGER NOT NULL REFERENCES organizations(id), pin_code VARCHAR(10) NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (user_id, organization_id) );"; ExecuteSql(sql); } /// /// Sets up Row Level Security (RLS) for the organizations and user_organizations tables. /// void SetupRLS() { var sql = new[] { "ALTER TABLE organizations ENABLE ROW LEVEL SECURITY;", "ALTER TABLE user_organizations ENABLE ROW LEVEL SECURITY;", "DROP POLICY IF EXISTS organization_access ON organizations;", @"CREATE POLICY organization_access ON organizations USING (id IN ( SELECT organization_id FROM user_organizations WHERE user_id = current_setting('app.user_id', TRUE)::INTEGER ));", "DROP POLICY IF EXISTS user_organization_access ON user_organizations;", @"CREATE POLICY user_organization_access ON user_organizations USING (user_id = current_setting('app.user_id', TRUE)::INTEGER);" }; foreach (var statement in sql) { ExecuteSql(statement); } } } }