Files
git.stella-ops.org/deploy/postgres-validation/001_validate_rls.sql
StellaOps Bot b058dbe031 up
2025-12-14 23:20:14 +02:00

160 lines
5.0 KiB
SQL

-- RLS Validation Script
-- Sprint: SPRINT_3421_0001_0001 - RLS Expansion
--
-- Purpose: Verify that RLS is properly configured on all tenant-scoped tables
-- Run this script after deploying RLS migrations to validate configuration
-- ============================================================================
-- Part 1: List all tables with RLS status
-- ============================================================================
\echo '=== RLS Status for All Schemas ==='
SELECT
schemaname AS schema,
tablename AS table_name,
rowsecurity AS rls_enabled,
forcerowsecurity AS rls_forced,
CASE
WHEN rowsecurity AND forcerowsecurity THEN 'OK'
WHEN rowsecurity AND NOT forcerowsecurity THEN 'WARN: Not forced'
ELSE 'MISSING'
END AS status
FROM pg_tables
WHERE schemaname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns')
ORDER BY schemaname, tablename;
-- ============================================================================
-- Part 2: List all RLS policies
-- ============================================================================
\echo ''
\echo '=== RLS Policies ==='
SELECT
schemaname AS schema,
tablename AS table_name,
policyname AS policy_name,
permissive,
roles,
cmd AS applies_to,
qual IS NOT NULL AS has_using,
with_check IS NOT NULL AS has_check
FROM pg_policies
WHERE schemaname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns')
ORDER BY schemaname, tablename, policyname;
-- ============================================================================
-- Part 3: Tables missing RLS that should have it (have tenant_id column)
-- ============================================================================
\echo ''
\echo '=== Tables with tenant_id but NO RLS ==='
SELECT
c.table_schema AS schema,
c.table_name AS table_name,
'MISSING RLS' AS issue
FROM information_schema.columns c
JOIN pg_tables t ON c.table_schema = t.schemaname AND c.table_name = t.tablename
WHERE c.column_name IN ('tenant_id', 'tenant')
AND c.table_schema IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns')
AND NOT t.rowsecurity
ORDER BY c.table_schema, c.table_name;
-- ============================================================================
-- Part 4: Verify helper functions exist
-- ============================================================================
\echo ''
\echo '=== RLS Helper Functions ==='
SELECT
n.nspname AS schema,
p.proname AS function_name,
CASE
WHEN p.prosecdef THEN 'SECURITY DEFINER'
ELSE 'SECURITY INVOKER'
END AS security,
CASE
WHEN p.provolatile = 's' THEN 'STABLE'
WHEN p.provolatile = 'i' THEN 'IMMUTABLE'
ELSE 'VOLATILE'
END AS volatility
FROM pg_proc p
JOIN pg_namespace n ON p.pronamespace = n.oid
WHERE p.proname = 'require_current_tenant'
AND n.nspname LIKE '%_app'
ORDER BY n.nspname;
-- ============================================================================
-- Part 5: Test RLS enforcement (expect failure without tenant context)
-- ============================================================================
\echo ''
\echo '=== RLS Enforcement Test ==='
\echo 'Testing RLS on scheduler.runs (should fail without tenant context)...'
-- Reset tenant context
SELECT set_config('app.tenant_id', '', false);
DO $$
BEGIN
-- This should raise an exception if RLS is working
PERFORM * FROM scheduler.runs LIMIT 1;
RAISE NOTICE 'WARNING: Query succeeded without tenant context - RLS may not be working!';
EXCEPTION
WHEN OTHERS THEN
RAISE NOTICE 'OK: RLS blocked query without tenant context: %', SQLERRM;
END
$$;
-- ============================================================================
-- Part 6: Admin bypass role verification
-- ============================================================================
\echo ''
\echo '=== Admin Bypass Roles ==='
SELECT
rolname AS role_name,
rolbypassrls AS can_bypass_rls,
rolcanlogin AS can_login
FROM pg_roles
WHERE rolname LIKE '%_admin'
AND rolbypassrls = TRUE
ORDER BY rolname;
-- ============================================================================
-- Summary
-- ============================================================================
\echo ''
\echo '=== Summary ==='
SELECT
'Total Tables' AS metric,
COUNT(*)::TEXT AS value
FROM pg_tables
WHERE schemaname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns')
UNION ALL
SELECT
'Tables with RLS Enabled',
COUNT(*)::TEXT
FROM pg_tables
WHERE schemaname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns')
AND rowsecurity = TRUE
UNION ALL
SELECT
'Tables with RLS Forced',
COUNT(*)::TEXT
FROM pg_tables
WHERE schemaname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns')
AND forcerowsecurity = TRUE
UNION ALL
SELECT
'Active Policies',
COUNT(*)::TEXT
FROM pg_policies
WHERE schemaname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns');