c77_rbac/README.md

9.7 KiB
Raw Blame History

c77_rbac: Role-Based Access Control for PostgreSQL

c77_rbac is a PostgreSQL extension that provides a flexible Role-Based Access Control (RBAC) system for managing user permissions and enforcing data access policies at the database level. It is designed to integrate seamlessly with web applications (e.g., Laravel) while remaining universal for use in other environments. The extension allows you to define roles, assign features to roles, scope user access to specific entities (e.g., campuses or stores), and enforce row-level security (RLS) on tables based on user permissions.

Purpose and Goals

The c77_rbac extension aims to:

  • Centralize Access Control: Push permission logic into the database to ensure consistent access control across applications.
  • Support Scalability: Work for both small systems (e.g., a two-person shop) and large, complex organizations with hierarchical structures.
  • Integrate with Web Apps: Seamlessly integrate with frameworks like Laravel, leveraging their authentication systems (e.g., Laravels users table) while remaining framework-agnostic.
  • Enforce Row-Level Security: Use PostgreSQLs RLS to filter data based on user roles and scopes (e.g., a user can only see sales data for their assigned campus).
  • Provide Flexibility: Allow for scoped permissions (e.g., a user can manage sales in campus/chicago but not campus/miami) and future support for hierarchical entities (e.g., parent-child relationships between campuses).

Features

  • Role Assignment: Assign roles to users with specific scopes (e.g., sales_manager for campus/chicago).
  • Feature Grants: Grant features (permissions) to roles (e.g., view_sales_page to sales_manager).
  • Access Checks: Check if a user has access to a feature in a specific scope (e.g., public.c77_rbac.can_access('jane', 'view_sales_page', 'campus', 'chicago')).
  • Row-Level Security (RLS): Apply RLS policies to tables to filter rows based on user permissions (e.g., a user only sees sales data for their campus).
  • Cross-Schema Support: Apply RLS policies to tables in any schema (e.g., public.sales or other_schema.sales).

Current Status

What Weve Done So Far

  • Schema Design:

    • Created tables in the public schema with the c77_rbac_ prefix:
      • c77_rbac_users: Stores users with their scopes (e.g., jane, campus, chicago).
      • c77_rbac_roles: Stores roles (e.g., sales_manager, finance_officer).
      • c77_rbac_user_roles: Links users to roles with scopes.
      • c77_rbac_features: Stores features (e.g., view_sales_page, approve_payments).
      • c77_rbac_role_features: Links roles to features.
      • c77_rbac_entities: Placeholder for future hierarchical entity support (not yet implemented).
    • Committed to schema.sql.
  • Core Functions:

    • public.c77_rbac_assign_user(p_username TEXT, p_role_name TEXT, p_scope_type TEXT, p_scope_id TEXT): Assigns a role to a user with a specific scope, handling conflicts by updating existing entries.
    • public.c77_rbac_grant_feature(p_role_name TEXT, p_feature_name TEXT): Grants a feature to a role.
    • public.c77_rbac.can_access(p_username TEXT, p_feature_name TEXT, p_scope_type TEXT, p_scope_id TEXT): Checks if a user has access to a feature in a given scope. Updated to accept a p_username parameter for integration with app-level authentication (e.g., Laravels Auth::user()->username).
    • public.c77_rbac_apply_policy(p_schema_name TEXT, p_table_name TEXT, p_feature_name TEXT, p_scope_column TEXT): Applies an RLS policy to a table, filtering rows based on public.c77_rbac.can_access.
  • Testing:

    • Set up test data:
      • User jane with roles sales_manager and finance_officer for campus/chicago.
      • Features: view_sales_page for sales_manager, approve_payments for finance_officer.
    • Tested public.c77_rbac.can_access:
      • public.c77_rbac.can_access('jane', 'view_sales_page', 'campus', 'chicago')TRUE.
      • public.c77_rbac.can_access('jane', 'approve_payments', 'campus', 'chicago')TRUE.
      • public.c77_rbac.can_access('jane', 'view_sales_page', 'campus', 'miami')FALSE.
    • Created test tables public.sales and other_schema.sales with sample data (campus = 'chicago' and 'miami').
  • RLS Implementation:

    • Added public.c77_rbac_apply_policy to apply RLS policies to tables.
    • Used a session variable (c77_rbac.current_user) to pass the username to RLS policies.
    • Added public.c77_rbac_get_current_user() to safely fetch the session variable.
  • Permissions:

    • Granted SELECT, INSERT, UPDATE, DELETE on all c77_rbac_* tables to PUBLIC.
    • Granted EXECUTE on all functions to PUBLIC.
    • Documented the need for USAGE on non-public schemas (e.g., GRANT USAGE ON SCHEMA other_schema TO PUBLIC;).

Whats Left to Do

  • Fix RLS Filtering:

    • Currently, RLS policies on public.sales and other_schema.sales are not filtering rows as expected (Jane sees both chicago and miami rows, but should only see chicago).
    • Likely cause: The homestead role (or your default role) has the BYPASSRLS attribute, which bypasses RLS policies.
    • Next Steps:
      1. Check if homestead has BYPASSRLS:
        \du homestead
        
      2. Remove BYPASSRLS if present:
        ALTER ROLE homestead NOBYPASSRLS;
        
      3. Retest RLS:
        SET SESSION "c77_rbac.current_user" TO 'jane';
        SELECT * FROM public.sales; -- Should show only chicago row
        SELECT * FROM other_schema.sales; -- Should show only chicago row
        
      4. If still not working, add debugging to public.c77_rbac_get_current_user() to log the session variable value.
  • Package as Extension:

    • Create c77_rbac--1.0.sql by copying schema.sql and adding the extension header.
    • Create c77_rbac.control file.
    • Test installing the extension with CREATE EXTENSION c77_rbac.
  • Phase 3: Refinement & Flexibility:

    • Add support for c77_rbac_entities to handle hierarchical entities (e.g., parent-child relationships between campuses).
    • Test complex scenarios (e.g., auto group with many users) and simple scenarios (e.g., two-person shop).
    • Optimize with indexes on frequently queried columns (e.g., c77_rbac_users.username, c77_rbac_user_roles.user_id).
  • Phase 4: Documentation & Packaging:

    • Expand this README.md with detailed usage examples.
    • Add integration guides for other frameworks (e.g., Django, Rails).
    • Tag v1.0 in the Git repository (https://git.jctr3.com/c77_rbac).

Installation

  1. Install the Extension:

    • Copy c77_rbac--1.0.sql and c77_rbac.control to your PostgreSQL extension directory (e.g., /usr/share/postgresql/14/extension/).
    • Run:
      CREATE EXTENSION c77_rbac;
      
  2. Set Up Permissions:

    • Ensure your application role (e.g., app_user) has access to the schema and tables:
      GRANT USAGE ON SCHEMA public TO app_user;
      GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO app_user;
      
    • For tables in other schemas:
      GRANT USAGE ON SCHEMA other_schema TO app_user;
      GRANT SELECT, INSERT, UPDATE, DELETE ON other_schema.your_table TO app_user;
      

Usage

Assigning Roles and Features

-- Assign a role to a user with a scope
SELECT public.c77_rbac_assign_user('jane', 'sales_manager', 'campus', 'chicago');
SELECT public.c77_rbac_assign_user('jane', 'finance_officer', 'campus', 'chicago');

-- Grant features to roles
SELECT public.c77_rbac_grant_feature('sales_manager', 'view_sales_page');
SELECT public.c77_rbac_grant_feature('finance_officer', 'approve_payments');

Checking Access

-- Check if a user has access to a feature in a scope
SELECT public.c77_rbac.can_access('jane', 'view_sales_page', 'campus', 'chicago'); -- Returns TRUE
SELECT public.c77_rbac.can_access('jane', 'view_sales_page', 'campus', 'miami'); -- Returns FALSE

Applying RLS Policies

-- Create a table with a scope column (e.g., campus)
CREATE TABLE public.sales (
    id SERIAL PRIMARY KEY,
    campus TEXT NOT NULL,
    amount NUMERIC
);
INSERT INTO public.sales (campus, amount) VALUES ('chicago', 1000), ('miami', 2000);
GRANT SELECT, INSERT, UPDATE, DELETE ON public.sales TO PUBLIC;

-- Apply RLS policy
SELECT public.c77_rbac_apply_policy('public', 'sales', 'view_sales_page', 'campus');

-- Query as a user
SET SESSION "c77_rbac.current_user" TO 'jane';
SELECT * FROM public.sales; -- Should only show rows where campus = 'chicago'

Integration with Laravel

  1. Sync Users: Ensure usernames from Laravels users table are inserted into c77_rbac_users:

    use Illuminate\Support\Facades\DB;
    
    $user = Auth::user();
    DB::statement("SELECT public.c77_rbac_assign_user(?, ?, ?, ?)", [
        $user->username,
        'default_role', // Replace with the user's role
        'campus',       // Replace with the user's scope
        'chicago'       // Replace with the user's scope ID
    ]);
    
  2. Set the Session Username: Before running queries, set the session variable for RLS:

    DB::statement("SET SESSION \"c77_rbac.current_user\" TO ?", [Auth::user()->username]);
    
  3. Check Access:

    $hasAccess = DB::selectOne(
        "SELECT public.c77_rbac.can_access(?, ?, ?, ?)",
        [Auth::user()->username, 'view_sales_page', 'campus', 'chicago']
    )->public_c77_rbac_can_access;
    
    if ($hasAccess) {
        // Allow access
    }
    

Contributing

Contributions are welcome! Please submit issues or pull requests to the repository at https://git.jctr3.com/c77_rbac.

License

This project is licensed under the MIT License. See the LICENSE file for details (to be added).