# CONTRACT-FINDINGS-LEDGER-RLS-011: Row-Level Security & Partitioning > **Status:** Published > **Version:** 1.0.0 > **Published:** 2025-12-05 > **Owners:** Platform/DB Guild, Findings Ledger Guild > **Unblocks:** LEDGER-TEN-48-001-DEV, DEVOPS-LEDGER-TEN-48-001-REL ## Overview This contract specifies the Row-Level Security (RLS) and partitioning strategy for the Findings Ledger module. It is based on the proven Evidence Locker implementation pattern and adapted for Findings Ledger's schema. ## Current State (Already Implemented) The Findings Ledger already has these foundational elements: ### 1. LIST Partitioning by Tenant All tables are partitioned by `tenant_id`: ```sql -- Example from ledger_events CREATE TABLE ledger_events ( tenant_id TEXT NOT NULL, ... ) PARTITION BY LIST (tenant_id); ``` **Tables with partitioning:** - `ledger_events` - `ledger_merkle_roots` - `findings_projection` - `finding_history` - `triage_actions` - `ledger_attestations` - `orchestrator_exports` - `airgap_imports` ### 2. Session Variable Configuration Connection setup in `LedgerDataSource.cs`: ```csharp await using var cmd = connection.CreateCommand(); cmd.CommandText = "SELECT set_config('app.current_tenant', @tenant, false);"; cmd.Parameters.AddWithValue("tenant", tenantId); await cmd.ExecuteNonQueryAsync(ct); ``` ### 3. HTTP Header Tenant Extraction From `Program.cs`: - Header: `X-Stella-Tenant` - Validation: Non-empty required - Error: 400 Bad Request if missing ### 4. Application-Level Query Filtering All repository queries include `WHERE tenant_id = @tenant` (defense in depth). --- ## Required Implementation (The Missing 10%) ### 1. Tenant Validation Function Create a schema function following the Evidence Locker pattern: ```sql -- Schema for application-level functions CREATE SCHEMA IF NOT EXISTS findings_ledger_app; -- Tenant validation function (TEXT version for Ledger compatibility) CREATE OR REPLACE FUNCTION findings_ledger_app.require_current_tenant() RETURNS TEXT LANGUAGE plpgsql STABLE AS $$ DECLARE tenant_text TEXT; BEGIN tenant_text := current_setting('app.current_tenant', true); IF tenant_text IS NULL OR length(trim(tenant_text)) = 0 THEN RAISE EXCEPTION 'app.current_tenant is not set for the current session' USING ERRCODE = 'P0001'; END IF; RETURN tenant_text; END; $$; COMMENT ON FUNCTION findings_ledger_app.require_current_tenant() IS 'Returns the current tenant ID from session variable, raises exception if not set'; ``` ### 2. RLS Policies for All Tables Apply to each tenant-scoped table: ```sql -- ============================================ -- ledger_events -- ============================================ ALTER TABLE ledger_events ENABLE ROW LEVEL SECURITY; ALTER TABLE ledger_events FORCE ROW LEVEL SECURITY; CREATE POLICY ledger_events_tenant_isolation ON ledger_events FOR ALL USING (tenant_id = findings_ledger_app.require_current_tenant()) WITH CHECK (tenant_id = findings_ledger_app.require_current_tenant()); -- ============================================ -- ledger_merkle_roots -- ============================================ ALTER TABLE ledger_merkle_roots ENABLE ROW LEVEL SECURITY; ALTER TABLE ledger_merkle_roots FORCE ROW LEVEL SECURITY; CREATE POLICY ledger_merkle_roots_tenant_isolation ON ledger_merkle_roots FOR ALL USING (tenant_id = findings_ledger_app.require_current_tenant()) WITH CHECK (tenant_id = findings_ledger_app.require_current_tenant()); -- ============================================ -- findings_projection -- ============================================ ALTER TABLE findings_projection ENABLE ROW LEVEL SECURITY; ALTER TABLE findings_projection FORCE ROW LEVEL SECURITY; CREATE POLICY findings_projection_tenant_isolation ON findings_projection FOR ALL USING (tenant_id = findings_ledger_app.require_current_tenant()) WITH CHECK (tenant_id = findings_ledger_app.require_current_tenant()); -- ============================================ -- finding_history -- ============================================ ALTER TABLE finding_history ENABLE ROW LEVEL SECURITY; ALTER TABLE finding_history FORCE ROW LEVEL SECURITY; CREATE POLICY finding_history_tenant_isolation ON finding_history FOR ALL USING (tenant_id = findings_ledger_app.require_current_tenant()) WITH CHECK (tenant_id = findings_ledger_app.require_current_tenant()); -- ============================================ -- triage_actions -- ============================================ ALTER TABLE triage_actions ENABLE ROW LEVEL SECURITY; ALTER TABLE triage_actions FORCE ROW LEVEL SECURITY; CREATE POLICY triage_actions_tenant_isolation ON triage_actions FOR ALL USING (tenant_id = findings_ledger_app.require_current_tenant()) WITH CHECK (tenant_id = findings_ledger_app.require_current_tenant()); -- ============================================ -- ledger_attestations -- ============================================ ALTER TABLE ledger_attestations ENABLE ROW LEVEL SECURITY; ALTER TABLE ledger_attestations FORCE ROW LEVEL SECURITY; CREATE POLICY ledger_attestations_tenant_isolation ON ledger_attestations FOR ALL USING (tenant_id = findings_ledger_app.require_current_tenant()) WITH CHECK (tenant_id = findings_ledger_app.require_current_tenant()); -- ============================================ -- orchestrator_exports -- ============================================ ALTER TABLE orchestrator_exports ENABLE ROW LEVEL SECURITY; ALTER TABLE orchestrator_exports FORCE ROW LEVEL SECURITY; CREATE POLICY orchestrator_exports_tenant_isolation ON orchestrator_exports FOR ALL USING (tenant_id = findings_ledger_app.require_current_tenant()) WITH CHECK (tenant_id = findings_ledger_app.require_current_tenant()); -- ============================================ -- airgap_imports -- ============================================ ALTER TABLE airgap_imports ENABLE ROW LEVEL SECURITY; ALTER TABLE airgap_imports FORCE ROW LEVEL SECURITY; CREATE POLICY airgap_imports_tenant_isolation ON airgap_imports FOR ALL USING (tenant_id = findings_ledger_app.require_current_tenant()) WITH CHECK (tenant_id = findings_ledger_app.require_current_tenant()); ``` ### 3. System/Admin Bypass Role For migrations and cross-tenant admin operations: ```sql -- Create admin role that bypasses RLS CREATE ROLE findings_ledger_admin NOLOGIN; -- Grant bypass to admin role ALTER ROLE findings_ledger_admin BYPASSRLS; -- Application service account for migrations GRANT findings_ledger_admin TO stellaops_migration_user; ``` --- ## Connection Patterns ### Regular Connections (Tenant-Scoped) ```csharp public async Task OpenTenantConnectionAsync( string tenantId, CancellationToken ct) { var connection = await _dataSource.OpenConnectionAsync(ct); await using var cmd = connection.CreateCommand(); cmd.CommandText = "SELECT set_config('app.current_tenant', @tenant, false)"; cmd.Parameters.AddWithValue("tenant", tenantId); await cmd.ExecuteNonQueryAsync(ct); return connection; } ``` ### System Connections (No Tenant - Migrations Only) ```csharp public async Task OpenSystemConnectionAsync(CancellationToken ct) { // Uses admin role, no tenant set // ONLY for: migrations, health checks, cross-tenant admin ops var connection = await _adminDataSource.OpenConnectionAsync(ct); return connection; } ``` --- ## Compliance Validation ### Pre-Deployment Checks ```sql -- 1. Verify RLS enabled on all tables SELECT schemaname, tablename, rowsecurity FROM pg_tables WHERE schemaname = 'public' AND tablename IN ( 'ledger_events', 'ledger_merkle_roots', 'findings_projection', 'finding_history', 'triage_actions', 'ledger_attestations', 'orchestrator_exports', 'airgap_imports' ) AND rowsecurity = false; -- Expected: 0 rows (all should have RLS enabled) -- 2. Verify policies exist for all tables SELECT tablename, policyname FROM pg_policies WHERE schemaname = 'public' AND tablename IN ( 'ledger_events', 'ledger_merkle_roots', 'findings_projection', 'finding_history', 'triage_actions', 'ledger_attestations', 'orchestrator_exports', 'airgap_imports' ); -- Expected: 8 rows (one policy per table) -- 3. Verify tenant validation function exists SELECT proname, prosrc FROM pg_proc WHERE proname = 'require_current_tenant' AND pronamespace = (SELECT oid FROM pg_namespace WHERE nspname = 'findings_ledger_app'); -- Expected: 1 row ``` ### Runtime Regression Tests ```csharp [Fact] public async Task CrossTenantRead_ShouldFail_WithRlsError() { // Arrange: Insert data as tenant A await using var connA = await OpenTenantConnectionAsync("tenant-a", ct); await InsertFinding(connA, "finding-1", ct); // Act: Try to read as tenant B await using var connB = await OpenTenantConnectionAsync("tenant-b", ct); var result = await QueryFindings(connB, ct); // Assert: No rows returned (RLS blocks cross-tenant access) Assert.Empty(result); } [Fact] public async Task NoTenantContext_ShouldFail_WithException() { // Arrange: Open connection without setting tenant await using var conn = await _dataSource.OpenConnectionAsync(ct); // Act & Assert: Query should fail await Assert.ThrowsAsync(async () => { await conn.ExecuteAsync("SELECT * FROM ledger_events LIMIT 1"); }); } ``` --- ## Migration Strategy ### Migration File: `007_enable_rls.sql` ```sql -- Migration: Enable Row-Level Security for Findings Ledger -- Date: 2025-12-XX -- Task: LEDGER-TEN-48-001-DEV BEGIN; -- 1. Create app schema and tenant function CREATE SCHEMA IF NOT EXISTS findings_ledger_app; CREATE OR REPLACE FUNCTION findings_ledger_app.require_current_tenant() RETURNS TEXT LANGUAGE plpgsql STABLE AS $$ DECLARE tenant_text TEXT; BEGIN tenant_text := current_setting('app.current_tenant', true); IF tenant_text IS NULL OR length(trim(tenant_text)) = 0 THEN RAISE EXCEPTION 'app.current_tenant is not set' USING ERRCODE = 'P0001'; END IF; RETURN tenant_text; END; $$; -- 2. Enable RLS on all tables (see full SQL above) -- ... (apply to all 8 tables) -- 3. Create admin bypass role CREATE ROLE IF NOT EXISTS findings_ledger_admin NOLOGIN BYPASSRLS; COMMIT; ``` ### Rollback: `007_enable_rls_rollback.sql` ```sql BEGIN; -- Disable RLS on all tables ALTER TABLE ledger_events DISABLE ROW LEVEL SECURITY; ALTER TABLE ledger_merkle_roots DISABLE ROW LEVEL SECURITY; ALTER TABLE findings_projection DISABLE ROW LEVEL SECURITY; ALTER TABLE finding_history DISABLE ROW LEVEL SECURITY; ALTER TABLE triage_actions DISABLE ROW LEVEL SECURITY; ALTER TABLE ledger_attestations DISABLE ROW LEVEL SECURITY; ALTER TABLE orchestrator_exports DISABLE ROW LEVEL SECURITY; ALTER TABLE airgap_imports DISABLE ROW LEVEL SECURITY; -- Drop policies DROP POLICY IF EXISTS ledger_events_tenant_isolation ON ledger_events; DROP POLICY IF EXISTS ledger_merkle_roots_tenant_isolation ON ledger_merkle_roots; DROP POLICY IF EXISTS findings_projection_tenant_isolation ON findings_projection; DROP POLICY IF EXISTS finding_history_tenant_isolation ON finding_history; DROP POLICY IF EXISTS triage_actions_tenant_isolation ON triage_actions; DROP POLICY IF EXISTS ledger_attestations_tenant_isolation ON ledger_attestations; DROP POLICY IF EXISTS orchestrator_exports_tenant_isolation ON orchestrator_exports; DROP POLICY IF EXISTS airgap_imports_tenant_isolation ON airgap_imports; -- Drop function and schema DROP FUNCTION IF EXISTS findings_ledger_app.require_current_tenant(); DROP SCHEMA IF EXISTS findings_ledger_app; COMMIT; ``` --- ## Audit Requirements 1. **All write operations** must log `tenant_id` and `actor_id` 2. **System connections** must log reason and operator 3. **RLS bypass operations** must be audited separately 4. **Cross-tenant queries** (admin only) must require justification ticket --- ## Reference Implementation Evidence Locker RLS implementation: - `src/EvidenceLocker/StellaOps.EvidenceLocker/StellaOps.EvidenceLocker.Infrastructure/Db/Migrations/001_initial_schema.sql` --- ## Approval Checklist - [ ] Platform/DB Guild: Schema and RLS patterns approved - [ ] Security Guild: Tenant isolation verified - [ ] Findings Ledger Guild: Implementation feasible - [ ] DevOps Guild: Migration/rollback strategy approved --- ## Changelog | Version | Date | Author | Changes | |---------|------|--------|---------| | 1.0.0 | 2025-12-05 | Platform Guild | Initial contract based on Evidence Locker pattern |