148 lines
No EOL
4 KiB
C#
148 lines
No EOL
4 KiB
C#
using Insight.Database;
|
|
using System.Data;
|
|
|
|
namespace Database.IdentitySystem
|
|
{
|
|
public interface IDbSetup
|
|
{
|
|
void CreateSystem(string schema = null);
|
|
}
|
|
|
|
/// <summary>
|
|
/// This is by purpose not async await
|
|
/// </summary>
|
|
public class DbSetup : IDbSetup
|
|
{
|
|
readonly IDbConnection _db;
|
|
IDbTransaction _transaction = null;
|
|
string _schema;
|
|
|
|
public DbSetup(IDbConnection db)
|
|
{
|
|
_db = db;
|
|
}
|
|
|
|
/// <summary>
|
|
/// Creates the system tables in the specified schema within a transaction.
|
|
/// </summary>
|
|
/// <param name="schema">The schema name where the tables will be created.</param>
|
|
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);
|
|
}
|
|
|
|
|
|
/// <summary>
|
|
/// Creates the users table
|
|
/// </summary>
|
|
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);
|
|
|
|
}
|
|
|
|
/// <summary>
|
|
/// Creates the tenants table
|
|
/// </summary>
|
|
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);
|
|
|
|
}
|
|
|
|
/// <summary>
|
|
/// Creates the user_tenants table
|
|
/// </summary>
|
|
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);
|
|
|
|
}
|
|
|
|
/// <summary>
|
|
/// Sets up Row Level Security (RLS) for the tenants and user_tenants tables.
|
|
/// </summary>
|
|
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);
|
|
}
|
|
}
|
|
|
|
|
|
}
|
|
} |