2025-04-13 06:38:30 -05:00
2025-03-24 20:23:30 -05:00
2025-05-11 07:26:05 -05:00
2025-05-11 11:37:31 -05:00
2025-05-11 07:26:05 -05:00
2025-05-11 07:26:05 -05:00
2025-04-13 06:55:41 -05:00
2025-05-11 11:37:31 -05:00
2025-05-11 11:37:31 -05:00

c77_rbac PostgreSQL Extension

A PostgreSQL extension that provides Role-Based Access Control (RBAC) with Row-Level Security (RLS) for enterprise applications. This extension pushes authorization logic to the database layer, ensuring consistent security across all application frameworks and direct database access.

Features

  • Database-Centric Authorization: Authorization rules enforced at the database level
  • Row-Level Security: Fine-grained access control on individual rows
  • Scope-Based Permissions: Support for department, region, or any custom scope
  • Global Admin Support: Special global/all scope for administrative access
  • Framework Agnostic: Works with any application framework (Laravel, Rails, Django, etc.)
  • Dynamic Schema Support: Works with any PostgreSQL schema
  • Performance Optimized: Includes indexes and efficient access checks

Requirements

  • PostgreSQL 14 or later
  • Superuser access for initial installation

Installation

  1. Copy extension files to PostgreSQL directory:

    sudo cp c77_rbac.control /usr/share/postgresql/14/extension/
    sudo cp c77_rbac--1.0.sql /usr/share/postgresql/14/extension/
    
  2. Install the extension (requires superuser):

    -- Connect as superuser
    CREATE DATABASE your_db;
    CREATE USER app_user WITH PASSWORD 'secure_password';
    
    -- Install extension
    \c your_db
    CREATE EXTENSION c77_rbac;
    
    -- Grant necessary privileges to application user
    GRANT CREATE ON DATABASE your_db TO app_user;
    GRANT SELECT ON ALL TABLES IN SCHEMA public TO app_user;
    GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO app_user;
    GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO app_user;
    

Core Concepts

1. Subjects (Users)

  • Identified by an external_id (typically your application's user ID)
  • Can have multiple roles with different scopes

2. Roles

  • Named collections of features (permissions)
  • Can be scoped to specific contexts (department, region, etc.)

3. Features

  • Specific permissions that can be checked in policies
  • Examples: view_reports, edit_users, delete_records

4. Scopes

  • Context for role assignments
  • Examples: department/engineering, region/north, global/all

Basic Usage

1. Define Features and Roles

-- Define features (permissions)
SELECT public.c77_rbac_grant_feature('manager', 'view_reports');
SELECT public.c77_rbac_grant_feature('manager', 'edit_reports');
SELECT public.c77_rbac_grant_feature('admin', 'manage_users');

-- Admin roles should have all specific features
SELECT public.c77_rbac_grant_feature('admin', 'view_reports');
SELECT public.c77_rbac_grant_feature('admin', 'edit_reports');

2. Assign Users to Roles

-- Assign user to manager role for engineering department
SELECT public.c77_rbac_assign_subject('123', 'manager', 'department', 'engineering');

-- Assign admin with global access
SELECT public.c77_rbac_assign_subject('1', 'admin', 'global', 'all');

3. Apply Row-Level Security

-- Apply RLS policy to a table
SELECT public.c77_rbac_apply_policy(
    'myschema.reports',     -- table name (can be schema-qualified)
    'view_reports',         -- required feature
    'department',           -- scope type
    'department_id'         -- column containing scope value
);

4. Set User Context

-- Set the current user for RLS checks
SET "c77_rbac.external_id" TO '123';

-- Now queries automatically filter based on permissions
SELECT * FROM myschema.reports;  -- Only shows reports for user's department

Admin Management

Administrators with global/all scope need explicit feature grants. Use helper functions to manage this:

-- Sync all features to admin role
SELECT public.c77_rbac_sync_admin_features();

-- Or sync to all roles with global/all scope
SELECT public.c77_rbac_sync_global_admin_features();

Integration Examples

Laravel Integration

// Middleware to set user context
public function handle($request, Closure $next)
{
    if (Auth::check()) {
        DB::statement('SET "c77_rbac.external_id" TO ?', [Auth::id()]);
    }
    return $next($request);
}

// Check permissions
$canView = DB::selectOne("
    SELECT public.c77_rbac_can_access(?, ?, ?, ?) AS allowed
", ['view_reports', Auth::id(), 'department', 'engineering'])->allowed;

Schema-Aware Usage

-- Works with any schema
CREATE SCHEMA finance;
CREATE TABLE finance.accounts (...);

-- Apply RLS with schema qualification
SELECT public.c77_rbac_apply_policy(
    'finance.accounts',
    'view_finance',
    'department',
    'dept_id'
);

Available Functions

Core Functions

  • c77_rbac_assign_subject(external_id, role, scope_type, scope_id) - Assign role to user
  • c77_rbac_grant_feature(role, feature) - Grant feature to role
  • c77_rbac_can_access(feature, external_id, scope_type, scope_id) - Check access
  • c77_rbac_apply_policy(table, feature, scope_type, column) - Apply RLS policy

Admin Helper Functions

  • c77_rbac_sync_admin_features() - Sync all features to admin role
  • c77_rbac_sync_global_admin_features() - Sync features to all global/all roles

Maintenance Functions

  • c77_rbac_show_dependencies() - Show all dependencies on the extension
  • c77_rbac_remove_all_policies() - Remove all RLS policies
  • c77_rbac_cleanup_for_removal(remove_data) - Prepare for extension removal

Uninstallation

  1. Check dependencies:

    SELECT * FROM public.c77_rbac_show_dependencies();
    
  2. Remove policies and optionally data:

    -- Just remove policies
    SELECT public.c77_rbac_remove_all_policies();
    
    -- Or remove policies and all RBAC data
    SELECT public.c77_rbac_cleanup_for_removal(true);
    
  3. Drop the extension:

    DROP EXTENSION c77_rbac CASCADE;
    

Best Practices

  1. Feature Naming Convention:

    • Use prefixes: view_*, edit_*, delete_*, manage_*
    • Be specific: view_financial_reports vs view_reports
  2. Admin Setup:

    • Always grant specific features to admin roles
    • Use sync functions after adding new features
    • Document all features in your application
  3. Performance:

    • The extension includes optimized indexes
    • Use explain analyze to verify query plans
    • Consider materialized views for complex permission checks
  4. Security:

    • Always use parameterized queries
    • Reset session variables in connection pools
    • Audit role assignments regularly

Troubleshooting

No Data Returned

  1. Check if c77_rbac.external_id is set correctly
  2. Verify user has the required role and features
  3. Ensure RLS is enabled on the table
  4. Check that policies reference the correct columns

Policy Not Working

  1. Verify column names match between table and policy
  2. Check feature names match exactly
  3. Ensure scope types and IDs align

Performance Issues

  1. Verify indexes exist on RBAC tables
  2. Check query plans with EXPLAIN ANALYZE
  3. Consider caching permission checks in your application

Contributing

This extension is designed to be framework-agnostic. When contributing:

  • Keep the core extension simple and focused
  • Add framework-specific features to companion extensions
  • Include tests for new functionality
  • Update documentation for new features

License

MIT License - See LICENSE file for details

Support

  • Create an issue for bugs or feature requests
  • Check existing issues before creating new ones
  • Include PostgreSQL version and reproduction steps for bugs

For framework-specific extensions, see:

Description
Postgres Based RBAC
Readme 357 KiB
Languages
PLpgSQL 100%