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

15 KiB

c77_rbac Tutorial - Part 3: Implementing RBAC

Tutorial Navigation:


Chapter 3: Setting Up RBAC Roles and Features

Now we'll implement a comprehensive role-based access control system for our TechCorp database. This chapter covers defining features, creating roles, and assigning users to appropriate roles with proper scoping.

Step 1: Define Company-Wide Features

Features represent specific permissions that can be checked in your application. Let's define features that match our TechCorp organizational structure:

-- System Administration Features
SELECT public.c77_rbac_grant_feature('system_admin', 'manage_all_users');
SELECT public.c77_rbac_grant_feature('system_admin', 'access_all_departments');
SELECT public.c77_rbac_grant_feature('system_admin', 'view_all_salaries');
SELECT public.c77_rbac_grant_feature('system_admin', 'manage_system_settings');
SELECT public.c77_rbac_grant_feature('system_admin', 'view_audit_logs');
SELECT public.c77_rbac_grant_feature('system_admin', 'export_all_data');

-- Department Management Features
SELECT public.c77_rbac_grant_feature('dept_manager', 'view_dept_employees');
SELECT public.c77_rbac_grant_feature('dept_manager', 'manage_dept_projects');
SELECT public.c77_rbac_grant_feature('dept_manager', 'approve_dept_expenses');
SELECT public.c77_rbac_grant_feature('dept_manager', 'view_dept_salaries');
SELECT public.c77_rbac_grant_feature('dept_manager', 'create_dept_documents');
SELECT public.c77_rbac_grant_feature('dept_manager', 'view_confidential_docs');

-- Regular Employee Features
SELECT public.c77_rbac_grant_feature('employee', 'view_own_profile');
SELECT public.c77_rbac_grant_feature('employee', 'update_own_profile');
SELECT public.c77_rbac_grant_feature('employee', 'view_company_handbook');
SELECT public.c77_rbac_grant_feature('employee', 'submit_expenses');
SELECT public.c77_rbac_grant_feature('employee', 'view_own_expenses');
SELECT public.c77_rbac_grant_feature('employee', 'access_internal_docs');

-- Project Team Features
SELECT public.c77_rbac_grant_feature('project_member', 'view_project_details');
SELECT public.c77_rbac_grant_feature('project_member', 'edit_project_documents');
SELECT public.c77_rbac_grant_feature('project_member', 'view_project_expenses');
SELECT public.c77_rbac_grant_feature('project_member', 'submit_project_expenses');

SELECT public.c77_rbac_grant_feature('project_lead', 'manage_project_team');
SELECT public.c77_rbac_grant_feature('project_lead', 'approve_project_expenses');
SELECT public.c77_rbac_grant_feature('project_lead', 'create_project_documents');

-- Contractor Features (limited access)
SELECT public.c77_rbac_grant_feature('contractor', 'view_own_profile');
SELECT public.c77_rbac_grant_feature('contractor', 'view_assigned_projects');
SELECT public.c77_rbac_grant_feature('contractor', 'submit_expenses');
SELECT public.c77_rbac_grant_feature('contractor', 'access_project_docs');

-- HR Specific Features
SELECT public.c77_rbac_grant_feature('hr_staff', 'view_all_employees');
SELECT public.c77_rbac_grant_feature('hr_staff', 'manage_employee_data');
SELECT public.c77_rbac_grant_feature('hr_staff', 'access_hr_documents');
SELECT public.c77_rbac_grant_feature('hr_staff', 'view_salary_data');

-- Finance Specific Features
SELECT public.c77_rbac_grant_feature('finance_staff', 'view_all_expenses');
SELECT public.c77_rbac_grant_feature('finance_staff', 'approve_expenses');
SELECT public.c77_rbac_grant_feature('finance_staff', 'view_budget_data');
SELECT public.c77_rbac_grant_feature('finance_staff', 'access_financial_docs');

-- Sales Specific Features
SELECT public.c77_rbac_grant_feature('sales_staff', 'view_sales_data');
SELECT public.c77_rbac_grant_feature('sales_staff', 'manage_customer_info');
SELECT public.c77_rbac_grant_feature('sales_staff', 'access_sales_docs');

Step 2: Sync Admin Features

The admin role should have access to all features. Let's sync all existing features to the admin role:

-- Make sure system admin gets all features
SELECT public.c77_rbac_sync_admin_features();

-- Check what features were granted to admin
SELECT * FROM public.c77_rbac_get_role_features('admin');

-- Also sync features to our system_admin role
SELECT public.c77_rbac_sync_admin_features();

Step 3: Assign Roles to Users

Now we'll assign our TechCorp users to appropriate roles with proper scoping:

-- System Administrator (Alice)
SELECT public.c77_rbac_assign_subject('1', 'system_admin', 'global', 'all');

-- Department Managers
SELECT public.c77_rbac_assign_subject('101', 'dept_manager', 'department', 'ENG');  -- Bob
SELECT public.c77_rbac_assign_subject('201', 'dept_manager', 'department', 'SALES'); -- Frank
SELECT public.c77_rbac_assign_subject('301', 'dept_manager', 'department', 'HR');    -- Iris
SELECT public.c77_rbac_assign_subject('401', 'dept_manager', 'department', 'FIN');   -- Kelly
SELECT public.c77_rbac_assign_subject('501', 'dept_manager', 'department', 'MKT');   -- Maya

-- HR Staff (need special access across departments)
SELECT public.c77_rbac_assign_subject('301', 'hr_staff', 'global', 'all');  -- Iris (manager)
SELECT public.c77_rbac_assign_subject('302', 'hr_staff', 'global', 'all');  -- Jack

-- Finance Staff (need expense access across departments)
SELECT public.c77_rbac_assign_subject('401', 'finance_staff', 'global', 'all');  -- Kelly (manager)
SELECT public.c77_rbac_assign_subject('402', 'finance_staff', 'global', 'all');  -- Liam

-- Regular Employees (department-scoped)
SELECT public.c77_rbac_assign_subject('102', 'employee', 'department', 'ENG');
SELECT public.c77_rbac_assign_subject('103', 'employee', 'department', 'ENG');
SELECT public.c77_rbac_assign_subject('202', 'employee', 'department', 'SALES');
SELECT public.c77_rbac_assign_subject('203', 'employee', 'department', 'SALES');
SELECT public.c77_rbac_assign_subject('502', 'employee', 'department', 'MKT');

-- Contractors (department-scoped with limited access)
SELECT public.c77_rbac_assign_subject('104', 'contractor', 'department', 'ENG');

-- Project-specific roles
SELECT public.c77_rbac_assign_subject('101', 'project_lead', 'project', '1');  -- Bob leads Portal project
SELECT public.c77_rbac_assign_subject('103', 'project_lead', 'project', '2');  -- Dave leads Mobile project
SELECT public.c77_rbac_assign_subject('102', 'project_member', 'project', '1'); -- Carol on Portal
SELECT public.c77_rbac_assign_subject('102', 'project_member', 'project', '2'); -- Carol on Mobile
SELECT public.c77_rbac_assign_subject('104', 'project_member', 'project', '1'); -- Eve on Portal

-- Bulk assign basic employee role to all the additional users we created
SELECT * FROM public.c77_rbac_bulk_assign_subjects(
    (SELECT array_agg(id::text) FROM users WHERE id BETWEEN 1001 AND 1050),
    'employee',
    'department',
    'ENG'  -- Assign them all to engineering for this example
);

Step 4: Verify Role Assignments

Let's check that our role assignments are working correctly:

-- Check Alice's (admin) permissions
SELECT 'Alice (System Admin) - Roles:' as info;
SELECT * FROM public.c77_rbac_get_user_roles('1');

-- Check Bob's (engineering manager) permissions
SELECT 'Bob (Engineering Manager) - Roles:' as info;
SELECT * FROM public.c77_rbac_get_user_roles('101');

-- Check Carol's (developer) permissions
SELECT 'Carol (Developer) - Roles:' as info;
SELECT * FROM public.c77_rbac_get_user_roles('102');

-- Check Iris's (HR manager) permissions
SELECT 'Iris (HR Manager) - Roles:' as info;
SELECT * FROM public.c77_rbac_get_user_roles('301');

-- Check system summary
SELECT 'System Summary:' as info;
SELECT * FROM public.c77_rbac_summary;

Step 5: Understanding RBAC Scoping

Let's explore how different scoping patterns work in our system:

-- Global scope (system-wide access)
-- Example: Alice has system_admin role with global/all scope
SELECT 'Global Admin Access Example:' as demo;
SELECT public.c77_rbac_can_access('manage_all_users', '1', 'global', 'all') as alice_can_manage_all;

-- Department scope (department-specific access)
-- Example: Bob can manage engineering department but not sales
SELECT 'Department Scope Examples:' as demo;
SELECT public.c77_rbac_can_access('manage_dept_projects', '101', 'department', 'ENG') as bob_can_manage_eng;
SELECT public.c77_rbac_can_access('manage_dept_projects', '101', 'department', 'SALES') as bob_cannot_manage_sales;

-- Project scope (project-specific access)
-- Example: Carol is a member of projects 1 and 2
SELECT 'Project Scope Examples:' as demo;
SELECT public.c77_rbac_can_access('view_project_details', '102', 'project', '1') as carol_can_view_proj1;
SELECT public.c77_rbac_can_access('view_project_details', '102', 'project', '3') as carol_cannot_view_proj3;

-- Cross-department access for special roles
-- Example: Iris (HR) can access all departments
SELECT 'Cross-Department Access Example:' as demo;
SELECT public.c77_rbac_can_access('view_all_employees', '301', 'global', 'all') as iris_can_see_all;

Step 6: Create Role Hierarchy Visualization

Let's create a query to visualize our role hierarchy:

-- Create a comprehensive view of our RBAC setup
SELECT 'TechCorp RBAC Role Distribution:' as title;

SELECT 
    r.name as role_name,
    sr.scope_type,
    sr.scope_id,
    count(*) as user_count,
    string_agg(s.external_id, ', ' ORDER BY s.external_id::integer) as user_ids
FROM public.c77_rbac_roles r
JOIN public.c77_rbac_subject_roles sr ON r.role_id = sr.role_id
JOIN public.c77_rbac_subjects s ON sr.subject_id = s.subject_id
GROUP BY r.name, sr.scope_type, sr.scope_id
ORDER BY r.name, sr.scope_type, sr.scope_id;

-- Show feature distribution across roles
SELECT 'Feature Distribution:' as title;

SELECT 
    r.name as role_name,
    count(f.name) as feature_count,
    string_agg(f.name, ', ' ORDER BY f.name) as features
FROM public.c77_rbac_roles r
JOIN public.c77_rbac_role_features rf ON r.role_id = rf.role_id
JOIN public.c77_rbac_features f ON rf.feature_id = f.feature_id
GROUP BY r.name
ORDER BY count(f.name) DESC, r.name;

Checkpoint 3: You now have a complete RBAC setup with realistic corporate roles!


Understanding Our RBAC Structure

Role Hierarchy

  1. System Admin (system_admin)

    • Scope: global/all
    • Access: Everything across all departments and projects
    • Users: Alice (ID: 1)
  2. Department Managers (dept_manager)

    • Scope: department/[DEPT_CODE]
    • Access: Full control within their department
    • Users: Bob (ENG), Frank (SALES), Iris (HR), Kelly (FIN), Maya (MKT)
  3. Specialized Staff

    • HR Staff (hr_staff): Global access to employee data
    • Finance Staff (finance_staff): Global access to financial data
    • Sales Staff (sales_staff): Access to sales-specific features
  4. Regular Employees (employee)

    • Scope: department/[DEPT_CODE]
    • Access: Basic departmental access and own data
  5. Project Roles

    • Project Leads (project_lead): Scope: project/[PROJECT_ID]
    • Project Members (project_member): Scope: project/[PROJECT_ID]
  6. Contractors (contractor)

    • Scope: department/[DEPT_CODE] or project/[PROJECT_ID]
    • Access: Limited, task-specific access

Key Scopes Used

  • global/all: System-wide access (admins, HR, finance)
  • department/[CODE]: Department-specific access (ENG, SALES, HR, FIN, MKT)
  • project/[ID]: Project-specific access (1, 2, 3, 4, 5)

Permission Patterns

  • Inheritance: Users can have multiple roles with different scopes
  • Escalation: global/all scope overrides specific scopes
  • Isolation: Department and project scopes provide isolation
  • Flexibility: Same user can have different roles in different contexts

Advanced Role Management

Adding New Roles Dynamically

-- Example: Create a "Senior Developer" role with enhanced permissions
SELECT public.c77_rbac_grant_feature('senior_developer', 'view_project_details');
SELECT public.c77_rbac_grant_feature('senior_developer', 'edit_project_documents');
SELECT public.c77_rbac_grant_feature('senior_developer', 'mentor_junior_developers');
SELECT public.c77_rbac_grant_feature('senior_developer', 'approve_code_reviews');

-- Assign Dave as a senior developer in the engineering department
SELECT public.c77_rbac_assign_subject('103', 'senior_developer', 'department', 'ENG');

-- Verify the assignment
SELECT * FROM public.c77_rbac_get_user_roles('103');

Bulk Role Operations

-- Example: Assign all engineering employees to a "code_reviewer" role
-- First create the role
SELECT public.c77_rbac_grant_feature('code_reviewer', 'review_code');
SELECT public.c77_rbac_grant_feature('code_reviewer', 'comment_on_pull_requests');

-- Bulk assign to engineering employees
SELECT * FROM public.c77_rbac_bulk_assign_subjects(
    ARRAY['101', '102', '103', '104'],  -- Engineering team
    'code_reviewer',
    'department',
    'ENG'
);

Temporary Access Patterns

-- Example: Grant temporary access for a cross-departmental project
-- Marketing person needs temporary engineering access for a joint project
SELECT public.c77_rbac_assign_subject('502', 'project_member', 'project', '1');

-- Later, you can revoke this access
-- SELECT public.c77_rbac_revoke_subject_role('502', 'project_member', 'project', '1');

What's Next?

Now that we have a comprehensive RBAC system set up, in Part 4 we'll implement Row-Level Security (RLS) policies that will automatically enforce these permissions at the database level:

  • Apply RLS policies to our TechCorp tables
  • Implement sophisticated business rules for document access
  • Create multi-level security controls
  • Test automatic data filtering based on user roles

Continue to Part 4: Row-Level Security


Chapter Summary

In this chapter, you've successfully:

Created a Comprehensive Permission System

  • 40+ features covering all aspects of TechCorp operations
  • 10+ roles with realistic corporate hierarchy
  • 65+ user assignments with proper scoping

Implemented Advanced Scoping Patterns

  • Global access for system admins and cross-departmental roles
  • Department isolation for managers and employees
  • Project-based collaboration for cross-functional teams
  • Contractor limitations for external workers

Demonstrated RBAC Flexibility

  • Multiple roles per user (e.g., department manager + project lead)
  • Hierarchical permissions (global overrides departmental)
  • Dynamic role assignment for changing business needs
  • Bulk operations for efficient management

Established Security Foundation

  • Role-based feature access with proper validation
  • Scoped permissions preventing unauthorized access
  • Audit-ready structure with timestamps and tracking
  • Scalable design that grows with organizational needs

The RBAC system is now ready for Row-Level Security implementation, which will automatically enforce these permissions at the database query level.