c77_rbac/TUTORIAL-P4.md
2025-05-23 23:29:45 -05:00

28 KiB

c77_rbac Tutorial - Part 4: Row-Level Security

Tutorial Navigation:


Chapter 4: Implementing Row-Level Security

Now we'll apply Row-Level Security (RLS) policies to our TechCorp tables. This is where the magic happens - the database will automatically filter data based on user permissions without any changes to your application code.

Step 1: Apply RLS to User Data

Let's start with the users table, implementing a policy that allows users to see their own data, managers to see their department, and HR to see everyone:

-- Users can see their own profile + department colleagues + HR can see all
CREATE POLICY users_access_policy ON users FOR ALL
USING (
    -- Users can see their own record
    id::text = current_setting('c77_rbac.external_id', true) OR
    
    -- Department managers can see their department
    public.c77_rbac_can_access('view_dept_employees', 
        current_setting('c77_rbac.external_id', true), 
        'department', 
        (SELECT code FROM departments WHERE id = department_id)) OR
        
    -- HR can see all employees
    public.c77_rbac_can_access('view_all_employees',
        current_setting('c77_rbac.external_id', true),
        'global', 'all') OR
        
    -- System admin can see all
    public.c77_rbac_can_access('manage_all_users',
        current_setting('c77_rbac.external_id', true),
        'global', 'all')
);

ALTER TABLE users ENABLE ROW LEVEL SECURITY;

Step 2: Apply RLS to Projects

Project access should be limited to team members, department managers, and administrators:

-- Project access: team members + department managers + admin
CREATE POLICY projects_access_policy ON projects FOR ALL
USING (
    -- Project team members can see their projects
    EXISTS (
        SELECT 1 FROM project_members pm 
        WHERE pm.project_id = id 
        AND pm.user_id::text = current_setting('c77_rbac.external_id', true)
    ) OR
    
    -- Department managers can see their department's projects
    public.c77_rbac_can_access('manage_dept_projects',
        current_setting('c77_rbac.external_id', true),
        'department',
        (SELECT code FROM departments WHERE id = department_id)) OR
        
    -- System admin can see all
    public.c77_rbac_can_access('access_all_departments',
        current_setting('c77_rbac.external_id', true),
        'global', 'all')
);

ALTER TABLE projects ENABLE ROW LEVEL SECURITY;

Step 3: Apply RLS to Documents with Security Levels

This is where we implement our most sophisticated policy - documents with multiple security levels:

-- Complex document access based on security levels and scope
CREATE OR REPLACE FUNCTION can_access_document(
    p_document_id INTEGER,
    p_user_id TEXT
) RETURNS BOOLEAN LANGUAGE plpgsql SECURITY DEFINER AS $$
DECLARE
    doc RECORD;
BEGIN
    -- Get document details
    SELECT d.*, dept.code as dept_code 
    INTO doc
    FROM documents d
    JOIN departments dept ON d.department_id = dept.id
    WHERE d.id = p_document_id;
    
    -- Author can always access their documents
    IF doc.author_id::text = p_user_id THEN
        RETURN TRUE;
    END IF;
    
    -- Check by security level
    CASE doc.security_level
        WHEN 'public' THEN
            RETURN TRUE;
            
        WHEN 'internal' THEN
            RETURN public.c77_rbac_can_access('access_internal_docs', p_user_id, 'global', 'all');
            
        WHEN 'confidential' THEN
            -- Department managers and HR can see confidential docs
            RETURN public.c77_rbac_can_access('view_confidential_docs', p_user_id, 'department', doc.dept_code) OR
                   public.c77_rbac_can_access('access_hr_documents', p_user_id, 'global', 'all');
                   
        WHEN 'restricted' THEN
            -- Only finance staff and admin can see restricted docs
            RETURN public.c77_rbac_can_access('access_financial_docs', p_user_id, 'global', 'all') OR
                   public.c77_rbac_can_access('manage_all_users', p_user_id, 'global', 'all');
                   
        ELSE
            RETURN FALSE;
    END CASE;
END;
$$;

-- Apply the complex policy
CREATE POLICY documents_access_policy ON documents FOR ALL
USING (can_access_document(id, current_setting('c77_rbac.external_id', true)));

ALTER TABLE documents ENABLE ROW LEVEL SECURITY;

Step 4: Apply RLS to Expenses

Expense access should follow approval workflows - submitters, managers, finance staff:

-- Expense access: submitter + department manager + finance + admin
CREATE POLICY expenses_access_policy ON expenses FOR ALL
USING (
    -- Users can see their own expenses
    submitted_by::text = current_setting('c77_rbac.external_id', true) OR
    
    -- Department managers can see their department expenses
    public.c77_rbac_can_access('approve_dept_expenses',
        current_setting('c77_rbac.external_id', true),
        'department',
        (SELECT code FROM departments WHERE id = department_id)) OR
        
    -- Finance staff can see all expenses
    public.c77_rbac_can_access('view_all_expenses',
        current_setting('c77_rbac.external_id', true),
        'global', 'all') OR
        
    -- Project leads can see project expenses
    (project_id IS NOT NULL AND 
     public.c77_rbac_can_access('approve_project_expenses',
        current_setting('c77_rbac.external_id', true),
        'project', project_id::text)) OR
        
    -- System admin can see all
    public.c77_rbac_can_access('access_all_departments',
        current_setting('c77_rbac.external_id', true),
        'global', 'all')
);

ALTER TABLE expenses ENABLE ROW LEVEL SECURITY;

Step 5: Apply RLS to Project Members

Project team visibility should be controlled based on project access:

-- Project members table access
CREATE POLICY project_members_access_policy ON project_members FOR ALL
USING (
    -- Users can see their own memberships
    user_id::text = current_setting('c77_rbac.external_id', true) OR
    
    -- Project leads can see their project teams
    public.c77_rbac_can_access('manage_project_team',
        current_setting('c77_rbac.external_id', true),
        'project', project_id::text) OR
        
    -- Department managers can see their department's project teams
    EXISTS (
        SELECT 1 FROM projects p
        JOIN departments d ON p.department_id = d.id
        WHERE p.id = project_id
        AND public.c77_rbac_can_access('manage_dept_projects',
            current_setting('c77_rbac.external_id', true),
            'department', d.code)
    ) OR
    
    -- HR and Admin can see all
    public.c77_rbac_can_access('view_all_employees',
        current_setting('c77_rbac.external_id', true),
        'global', 'all')
);

ALTER TABLE project_members ENABLE ROW LEVEL SECURITY;

Step 6: Apply Simple RLS to Departments

Department information should be visible to appropriate users:

-- Use the built-in c77_rbac_apply_policy function for simpler cases
-- Departments visible to those who can view department employees
SELECT public.c77_rbac_apply_policy(
    'departments',
    'view_dept_employees',
    'department',
    'code'
);

Checkpoint 4: All tables now have sophisticated row-level security policies!


Understanding RLS Policy Patterns

Pattern 1: Self-Access + Role-Based Access

-- Users can see their own data OR those with specific permissions
id::text = current_setting('c77_rbac.external_id', true) OR
public.c77_rbac_can_access('permission', user_id, 'scope_type', 'scope_id')

Pattern 2: Hierarchical Access

-- Multiple levels of access: department → global
public.c77_rbac_can_access('dept_permission', user_id, 'department', dept_code) OR
public.c77_rbac_can_access('global_permission', user_id, 'global', 'all')

Pattern 3: Complex Business Logic

-- Custom function for complex rules
can_access_document(id, current_setting('c77_rbac.external_id', true))

Pattern 4: Relationship-Based Access

-- Access based on relationships (project membership, etc.)
EXISTS (
    SELECT 1 FROM related_table rt 
    WHERE rt.foreign_key = id 
    AND rt.user_id::text = current_setting('c77_rbac.external_id', true)
)

Testing RLS Policies

Let's create a comprehensive test to verify our RLS policies work correctly:

-- Create a test function to verify RLS is working
CREATE OR REPLACE FUNCTION test_rls_policies()
RETURNS TABLE(
    test_name TEXT,
    user_name TEXT,
    table_name TEXT,
    visible_rows INTEGER,
    expected_result TEXT,
    status TEXT
) LANGUAGE plpgsql AS $$
DECLARE
    test_users TEXT[] := ARRAY['1', '101', '102', '104', '301', '401'];
    test_user TEXT;
    user_name_val TEXT;
    row_count INTEGER;
BEGIN
    FOREACH test_user IN ARRAY test_users LOOP
        -- Set user context
        PERFORM set_config('c77_rbac.external_id', test_user, true);
        
        -- Get user name
        SELECT first_name || ' ' || last_name INTO user_name_val
        FROM users WHERE id::text = test_user;
        
        -- Test users table
        SELECT count(*) INTO row_count FROM users;
        RETURN QUERY SELECT 
            'User Visibility'::TEXT,
            user_name_val,
            'users'::TEXT,
            row_count,
            CASE 
                WHEN test_user = '1' THEN 'All users (admin)'
                WHEN test_user = '301' THEN 'All users (HR)'
                WHEN test_user IN ('101', '401') THEN 'Department + self'
                ELSE 'Limited (self + some colleagues)'
            END,
            CASE 
                WHEN test_user IN ('1', '301') AND row_count > 50 THEN 'PASS'
                WHEN test_user NOT IN ('1', '301') AND row_count < 50 THEN 'PASS'
                ELSE 'REVIEW'
            END;
            
        -- Test documents table
        SELECT count(*) INTO row_count FROM documents;
        RETURN QUERY SELECT 
            'Document Access'::TEXT,
            user_name_val,
            'documents'::TEXT,
            row_count,
            CASE 
                WHEN test_user = '1' THEN 'All documents (admin)'
                WHEN test_user = '401' THEN 'Including restricted (finance)'
                WHEN test_user IN ('101', '301') THEN 'Including confidential (manager/HR)'
                ELSE 'Internal and own documents only'
            END,
            CASE WHEN row_count > 0 THEN 'PASS' ELSE 'FAIL' END;
            
        -- Test expenses table
        SELECT count(*) INTO row_count FROM expenses;
        RETURN QUERY SELECT 
            'Expense Visibility'::TEXT,
            user_name_val,
            'expenses'::TEXT,
            row_count,
            CASE 
                WHEN test_user IN ('1', '401') THEN 'All expenses'
                WHEN test_user IN ('101', '301') THEN 'Department expenses'
                ELSE 'Own expenses only'
            END,
            CASE WHEN row_count > 0 THEN 'PASS' ELSE 'REVIEW' END;
    END LOOP;
    
    -- Reset context
    PERFORM set_config('c77_rbac.external_id', '', true);
END;
$$;

-- Run the comprehensive test
SELECT * FROM test_rls_policies() ORDER BY user_name, test_name;

Manual Testing Examples

-- Test as Alice (System Admin) - should see everything
SET "c77_rbac.external_id" TO '1';
SELECT 'Alice (Admin) sees ' || count(*) || ' users' FROM users;
SELECT 'Alice (Admin) sees ' || count(*) || ' documents' FROM documents;
SELECT 'Alice (Admin) sees ' || count(*) || ' expenses' FROM expenses;

-- Test as Bob (Eng Manager) - should see engineering department
SET "c77_rbac.external_id" TO '101';
SELECT 'Bob (Eng Manager) sees ' || count(*) || ' users' FROM users;
SELECT 'Bob (Eng Manager) sees ' || count(*) || ' documents' FROM documents;
SELECT 'Bob (Eng Manager) sees ' || count(*) || ' expenses' FROM expenses;

-- Test as Carol (Developer) - should see limited data
SET "c77_rbac.external_id" TO '102';
SELECT 'Carol (Developer) sees ' || count(*) || ' users' FROM users;
SELECT 'Carol (Developer) sees ' || count(*) || ' documents' FROM documents;
SELECT 'Carol (Developer) sees ' || count(*) || ' expenses' FROM expenses;

-- Test as Eve (Contractor) - should see very limited data
SET "c77_rbac.external_id" TO '104';
SELECT 'Eve (Contractor) sees ' || count(*) || ' users' FROM users;
SELECT 'Eve (Contractor) sees ' || count(*) || ' documents' FROM documents;
SELECT 'Eve (Contractor) sees ' || count(*) || ' expenses' FROM expenses;

-- Test document security levels specifically
SET "c77_rbac.external_id" TO '102'; -- Carol (regular employee)
SELECT 'Carol can see these document security levels:' as info;
SELECT security_level, count(*) 
FROM documents 
GROUP BY security_level 
ORDER BY security_level;

SET "c77_rbac.external_id" TO '401'; -- Kelly (Finance manager)
SELECT 'Kelly can see these document security levels:' as info;
SELECT security_level, count(*) 
FROM documents 
GROUP BY security_level 
ORDER BY security_level;

-- Reset context
RESET "c77_rbac.external_id";

Advanced RLS Patterns

Time-Based Access Control

-- Example: Add time-based restrictions to sensitive documents
CREATE OR REPLACE FUNCTION can_access_document_with_time(
    p_document_id INTEGER,
    p_user_id TEXT
) RETURNS BOOLEAN LANGUAGE plpgsql SECURITY DEFINER AS $$
DECLARE
    doc RECORD;
    current_hour INTEGER;
BEGIN
    -- Get document and current time
    SELECT * INTO doc FROM documents WHERE id = p_document_id;
    current_hour := EXTRACT(HOUR FROM CURRENT_TIME);
    
    -- Restricted documents only accessible during business hours (9-17)
    IF doc.security_level = 'restricted' THEN
        IF current_hour < 9 OR current_hour >= 17 THEN
            -- Only allow admin access outside business hours
            RETURN public.c77_rbac_can_access('manage_all_users', p_user_id, 'global', 'all');
        END IF;
    END IF;
    
    -- Fall back to regular document access rules
    RETURN can_access_document(p_document_id, p_user_id);
END;
$$;

Conditional Write Policies

-- Example: Only allow expense updates by submitter or approver
CREATE POLICY expenses_update_policy ON expenses FOR UPDATE
USING (
    -- Submitter can update before approval
    (submitted_by::text = current_setting('c77_rbac.external_id', true) AND status = 'submitted') OR
    
    -- Department managers can update their department's expenses
    public.c77_rbac_can_access('approve_dept_expenses',
        current_setting('c77_rbac.external_id', true),
        'department',
        (SELECT code FROM departments WHERE id = department_id)) OR
        
    -- Finance staff can update any expense
    public.c77_rbac_can_access('approve_expenses',
        current_setting('c77_rbac.external_id', true),
        'global', 'all')
);

Audit Trail Integration

-- Example: Automatic audit logging when accessing sensitive documents
CREATE OR REPLACE FUNCTION log_document_access()
RETURNS TRIGGER LANGUAGE plpgsql AS $$
BEGIN
    -- Log access to confidential or restricted documents
    IF NEW.security_level IN ('confidential', 'restricted') THEN
        INSERT INTO audit_log (
            user_id, 
            action, 
            table_name, 
            record_id,
            new_values
        ) VALUES (
            current_setting('c77_rbac.external_id', true)::integer,
            'document_accessed',
            'documents',
            NEW.id,
            jsonb_build_object(
                'document_title', NEW.title,
                'security_level', NEW.security_level,
                'access_time', CURRENT_TIMESTAMP
            )
        );
    END IF;
    RETURN NEW;
END;
$$;

-- Apply the audit trigger
CREATE TRIGGER document_access_audit
    AFTER SELECT ON documents
    FOR EACH ROW 
    EXECUTE FUNCTION log_document_access();

Performance Considerations

Index Optimization for RLS

-- Add indexes to support RLS policy performance
CREATE INDEX idx_users_department_id ON users(department_id);
CREATE INDEX idx_documents_author_security ON documents(author_id, security_level);
CREATE INDEX idx_documents_dept_security ON documents(department_id, security_level);
CREATE INDEX idx_expenses_submitter ON expenses(submitted_by);
CREATE INDEX idx_expenses_dept_status ON expenses(department_id, status);
CREATE INDEX idx_project_members_user_project ON project_members(user_id, project_id);

-- Analyze performance of RLS policies
CREATE OR REPLACE FUNCTION analyze_rls_performance()
RETURNS TABLE(
    table_name TEXT,
    policy_name TEXT,
    avg_execution_time TEXT,
    recommendations TEXT
) LANGUAGE plpgsql AS $
BEGIN
    RETURN QUERY
    SELECT 
        'Performance Analysis'::TEXT as table_name,
        'RLS Policies'::TEXT as policy_name,
        'Run EXPLAIN ANALYZE on queries'::TEXT as avg_execution_time,
        'Monitor slow queries and add indexes as needed'::TEXT as recommendations;
END;
$;

Query Optimization Examples

-- Example: Optimized query patterns that work well with RLS

-- Good: Use specific filters that align with RLS policies
SET "c77_rbac.external_id" TO '101'; -- Bob (Eng Manager)
EXPLAIN ANALYZE 
SELECT u.first_name, u.last_name, d.name as department
FROM users u 
JOIN departments d ON u.department_id = d.id
WHERE d.code = 'ENG';  -- This aligns with Bob's department scope

-- Good: Project-specific queries for project members
SET "c77_rbac.external_id" TO '102'; -- Carol (Developer)
EXPLAIN ANALYZE
SELECT p.name, p.status, pm.role
FROM projects p
JOIN project_members pm ON p.id = pm.project_id
WHERE pm.user_id = 102;  -- Explicit filter that matches RLS logic

-- Reset context
RESET "c77_rbac.external_id";

Troubleshooting RLS Issues

Common Problems and Solutions

-- Debug function to help troubleshoot RLS issues
CREATE OR REPLACE FUNCTION debug_rls_access(
    p_table_name TEXT,
    p_user_id TEXT,
    p_expected_rows INTEGER DEFAULT NULL
)
RETURNS TABLE(
    check_type TEXT,
    result TEXT,
    details TEXT
) LANGUAGE plpgsql AS $
DECLARE
    actual_rows INTEGER;
    rls_enabled BOOLEAN;
    policy_count INTEGER;
BEGIN
    -- Set user context
    PERFORM set_config('c77_rbac.external_id', p_user_id, true);
    
    -- Check if RLS is enabled
    SELECT INTO rls_enabled 
        EXISTS (
            SELECT 1 FROM pg_class c 
            JOIN pg_namespace n ON c.relnamespace = n.oid
            WHERE n.nspname = 'public' 
            AND c.relname = p_table_name
            AND c.relrowsecurity = true
        );
    
    RETURN QUERY SELECT 
        'RLS Enabled'::TEXT,
        CASE WHEN rls_enabled THEN 'YES' ELSE 'NO' END,
        'Row Level Security status on table'::TEXT;
    
    -- Count policies
    SELECT count(*) INTO policy_count
    FROM pg_policies 
    WHERE schemaname = 'public' 
    AND tablename = p_table_name;
    
    RETURN QUERY SELECT 
        'Policy Count'::TEXT,
        policy_count::TEXT,
        'Number of RLS policies on table'::TEXT;
    
    -- Count actual visible rows
    EXECUTE format('SELECT count(*) FROM %I', p_table_name) INTO actual_rows;
    
    RETURN QUERY SELECT 
        'Visible Rows'::TEXT,
        actual_rows::TEXT,
        'Rows visible to current user'::TEXT;
    
    -- Check user permissions
    RETURN QUERY SELECT 
        'User Context'::TEXT,
        p_user_id,
        'Current c77_rbac.external_id setting'::TEXT;
    
    -- Check user roles
    RETURN QUERY SELECT 
        'User Roles'::TEXT,
        count(*)::TEXT,
        'Total roles assigned to user'::TEXT
    FROM public.c77_rbac_get_user_roles(p_user_id);
    
    -- Compare with expectation if provided
    IF p_expected_rows IS NOT NULL THEN
        RETURN QUERY SELECT 
            'Expectation Check'::TEXT,
            CASE 
                WHEN actual_rows = p_expected_rows THEN 'MATCH'
                WHEN actual_rows < p_expected_rows THEN 'FEWER THAN EXPECTED'
                ELSE 'MORE THAN EXPECTED'
            END,
            format('Expected %s, got %s', p_expected_rows, actual_rows);
    END IF;
    
    -- Reset context
    PERFORM set_config('c77_rbac.external_id', '', true);
END;
$;

-- Usage examples:
SELECT * FROM debug_rls_access('users', '102');  -- Carol should see limited users
SELECT * FROM debug_rls_access('documents', '401', 10);  -- Kelly should see more documents
SELECT * FROM debug_rls_access('expenses', '104');  -- Eve (contractor) should see few expenses

Policy Testing Framework

-- Comprehensive RLS testing framework
CREATE OR REPLACE FUNCTION test_rls_comprehensive()
RETURNS TABLE(
    test_category TEXT,
    test_name TEXT,
    user_tested TEXT,
    expected_behavior TEXT,
    actual_result TEXT,
    status TEXT
) LANGUAGE plpgsql AS $
DECLARE
    test_users RECORD;
    table_name TEXT;
    row_count INTEGER;
BEGIN
    -- Test each major user type
    FOR test_users IN 
        SELECT 
            u.id::text as user_id,
            u.first_name || ' ' || u.last_name as name,
            u.employee_type,
            d.code as dept_code
        FROM users u
        JOIN departments d ON u.department_id = d.id
        WHERE u.id IN (1, 101, 102, 104, 301, 401)
    LOOP
        -- Set user context
        PERFORM set_config('c77_rbac.external_id', test_users.user_id, true);
        
        -- Test Users Table Access
        SELECT count(*) INTO row_count FROM users;
        
        RETURN QUERY SELECT 
            'User Access'::TEXT,
            'Users Table Visibility'::TEXT,
            test_users.name,
            CASE 
                WHEN test_users.user_id IN ('1', '301') THEN 'See all users'
                WHEN test_users.employee_type = 'manager' THEN 'See department users'
                ELSE 'See limited users'
            END,
            'Sees ' || row_count || ' users',
            CASE 
                WHEN test_users.user_id IN ('1', '301') AND row_count >= 60 THEN 'PASS'
                WHEN test_users.employee_type = 'manager' AND row_count BETWEEN 5 AND 60 THEN 'PASS'
                WHEN test_users.employee_type NOT IN ('admin', 'manager') AND row_count <= 15 THEN 'PASS'
                ELSE 'REVIEW'
            END;
        
        -- Test Documents by Security Level
        FOR table_name IN SELECT unnest(ARRAY['public', 'internal', 'confidential', 'restricted']) LOOP
            EXECUTE format('SELECT count(*) FROM documents WHERE security_level = %L', table_name) 
            INTO row_count;
            
            RETURN QUERY SELECT 
                'Document Security'::TEXT,
                table_name || ' Documents',
                test_users.name,
                CASE 
                    WHEN table_name = 'public' THEN 'Should see all'
                    WHEN table_name = 'internal' AND test_users.user_id != '104' THEN 'Should see all'
                    WHEN table_name = 'confidential' AND test_users.employee_type IN ('admin', 'manager') THEN 'Should see some'
                    WHEN table_name = 'restricted' AND test_users.user_id IN ('1', '401') THEN 'Should see some'
                    ELSE 'Should see none or few'
                END,
                CASE WHEN row_count > 0 THEN 'Sees ' || row_count ELSE 'Sees none' END,
                CASE 
                    WHEN table_name = 'public' AND row_count > 0 THEN 'PASS'
                    WHEN table_name = 'internal' AND test_users.user_id != '104' AND row_count > 0 THEN 'PASS'
                    WHEN table_name = 'confidential' AND test_users.employee_type IN ('admin', 'manager') AND row_count > 0 THEN 'PASS'
                    WHEN table_name = 'restricted' AND test_users.user_id IN ('1', '401') AND row_count > 0 THEN 'PASS'
                    WHEN table_name = 'restricted' AND test_users.user_id NOT IN ('1', '401') AND row_count = 0 THEN 'PASS'
                    WHEN table_name = 'confidential' AND test_users.employee_type NOT IN ('admin', 'manager') AND row_count <= 1 THEN 'PASS'
                    ELSE 'REVIEW'
                END;
        END LOOP;
        
        -- Test Expense Access
        SELECT count(*) INTO row_count FROM expenses;
        
        RETURN QUERY SELECT 
            'Expense Access'::TEXT,
            'Expense Visibility'::TEXT,
            test_users.name,
            CASE 
                WHEN test_users.user_id IN ('1', '401') THEN 'See all expenses'
                WHEN test_users.employee_type = 'manager' THEN 'See department expenses'
                ELSE 'See own expenses only'
            END,
            'Sees ' || row_count || ' expenses',
            CASE WHEN row_count > 0 THEN 'PASS' ELSE 'REVIEW' END;
            
    END LOOP;
    
    -- Reset context
    PERFORM set_config('c77_rbac.external_id', '', true);
END;
$;

-- Run comprehensive RLS tests
SELECT * FROM test_rls_comprehensive() 
ORDER BY test_category, user_tested, test_name;

Checkpoint 4 Complete: You now have sophisticated Row-Level Security protecting all your data!


Understanding What We've Built

Multi-Layer Security System

  1. Application Layer: User authentication and basic authorization
  2. RBAC Layer: Role and feature-based permissions with flexible scoping
  3. Database Layer: Row-Level Security automatically filtering data
  4. Audit Layer: Comprehensive logging of sensitive data access

Security Levels Implemented

  1. Public: Accessible to everyone
  2. Internal: Accessible to employees (not contractors)
  3. Confidential: Accessible to managers and specialized staff
  4. Restricted: Accessible only to finance staff and administrators

Access Control Patterns

  1. Self-Access: Users can always see their own data
  2. Hierarchical Access: Managers see their department, admins see everything
  3. Role-Based Access: Specialized roles (HR, Finance) have cross-department access
  4. Project-Based Access: Team members see project-specific data
  5. Security-Level Access: Documents filtered by classification level

What's Next?

In Part 5, we'll thoroughly test our security system to ensure it works correctly:

  • Comprehensive security validation
  • Edge case testing
  • Permission verification
  • Performance analysis
  • Real-world scenario testing

Continue to Part 5: Testing and Validation


Chapter Summary

Implemented Comprehensive RLS Policies

  • Users table: Self + department + HR/admin access
  • Projects table: Team members + department managers + admin
  • Documents table: Multi-level security (public/internal/confidential/restricted)
  • Expenses table: Submitter + approver + finance workflow
  • Project members table: Project-based access control

Created Advanced Security Patterns

  • Multi-level document security with business logic
  • Hierarchical access control (department → global)
  • Role-based cross-department access for specialized staff
  • Project-based collaboration across departments
  • Self-service access for personal data

Built Debugging and Testing Tools

  • RLS debugging functions for troubleshooting
  • Comprehensive test framework for validation
  • Performance analysis tools for optimization
  • Policy verification utilities for maintenance

Established Production-Ready Security

  • Automatic data filtering without application changes
  • Consistent security enforcement across all access paths
  • Audit-ready structure with comprehensive logging
  • Scalable permission model that grows with the organization

The database now automatically enforces sophisticated business rules for data access, providing enterprise-grade security with zero application code changes required!