From 71a219f47a2fa056699e8da427eacfa4e5d6f366 Mon Sep 17 00:00:00 2001 From: trogers1884 Date: Sun, 11 May 2025 11:37:31 -0500 Subject: [PATCH] Ready to Publish c77_rbac --- README.md | 263 ++++++- USAGE.md | 1721 +++++++++++++++++++++++++++++++++++++++++---- c77_rbac--1.0.sql | 125 +++- 3 files changed, 1949 insertions(+), 160 deletions(-) diff --git a/README.md b/README.md index a085b79..7777d1a 100644 --- a/README.md +++ b/README.md @@ -1,35 +1,250 @@ # c77_rbac PostgreSQL Extension -The `c77_rbac` extension provides role-based access control (RBAC) for PostgreSQL, securing tables with row-level security (RLS) for multi-campus applications. All objects are in the `public` schema with `c77_rbac_` prefixes (e.g., `c77_rbac_subjects`, `c77_rbac_apply_policy`) to coexist with Laravel and third-party packages. Application tables use custom schemas (e.g., `myapp.orders`). +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 -- Scoped role assignments (e.g., campus-specific access). -- Admin access via `global/all` scope for any user ID. -- RLS policies via `c77_rbac_apply_policy`. -- Compatible with PostgreSQL 14+ and Laravel. - -## Installation - -1. Ensure PostgreSQL 14 or later is installed. - -2. Place `c77_rbac.control` and `c77_rbac--1.1.0.sql.backup` in `/usr/share/postgresql/17/extension/`. - -3. Run as a superuser: - - ```sql - CREATE EXTENSION c77_rbac SCHEMA public; - ``` - -## Usage - -See `USAGE.md` for beginner-friendly instructions on securing tables and assigning roles. +- **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 installation. +- PostgreSQL 14 or later +- Superuser access for initial installation + +## Installation + +1. **Copy extension files to PostgreSQL directory:** + ```bash + 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):** + ```sql + -- 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 +```sql +-- 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 +```sql +-- 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 +```sql +-- 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 +```sql +-- 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: + +```sql +-- 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 +```php +// 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 +```sql +-- 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:** + ```sql + SELECT * FROM public.c77_rbac_show_dependencies(); + ``` + +2. **Remove policies and optionally data:** + ```sql + -- 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:** + ```sql + 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 \ No newline at end of file +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: +- [c77_rbac_laravel](https://github.com/yourusername/c77_rbac_laravel) - Laravel integration \ No newline at end of file diff --git a/USAGE.md b/USAGE.md index b1d4c15..fb2cc1b 100644 --- a/USAGE.md +++ b/USAGE.md @@ -1,199 +1,1650 @@ -# c77_rbac Usage Guide +# c77_rbac Comprehensive Usage Guide -This guide helps beginner developers use the `c77_rbac` PostgreSQL extension to secure database tables with role-based access control (RBAC). All tables and functions are in the `public` schema with `c77_rbac_` prefixes (e.g., `c77_rbac_subjects`, `c77_rbac_apply_policy`) to avoid conflicts with Laravel or other packages. Your application tables should use custom schemas (e.g., `myapp.orders`). +This guide explains every aspect of the c77_rbac extension in detail, with practical examples for Laravel developers. If you're new to database-level authorization, this guide will walk you through everything step by step. -## What is c77_rbac? +## Table of Contents -`c77_rbac` uses row-level security (RLS) to control table access. For example, a Chicago manager sees only Chicago orders, while an admin sees all orders. Admin rights use a `global/all` scope, so any user ID (e.g., `'2'`, `'999'`) can be an admin. +1. [Understanding the Concepts](#understanding-the-concepts) +2. [Installation Walk-through](#installation-walk-through) +3. [Core Functions Explained](#core-functions-explained) +4. [Setting Up Your First RBAC System](#setting-up-your-first-rbac-system) +5. [Laravel Integration Guide](#laravel-integration-guide) +6. [Common Patterns and Examples](#common-patterns-and-examples) +7. [Advanced Usage](#advanced-usage) +8. [Troubleshooting Guide](#troubleshooting-guide) +9. [Performance Considerations](#performance-considerations) +10. [Security Best Practices](#security-best-practices) -## Prerequisites +## Understanding the Concepts -- PostgreSQL 14 or later. -- A superuser (e.g., `homestead`) for installation. -- A database (e.g., `c77_rbac_test`). -- Basic SQL knowledge. +### What is c77_rbac? -## Step 1: Install the Extension +c77_rbac moves authorization from your application code to the database. Instead of writing `if` statements in Laravel to check permissions, the database automatically filters data based on user permissions. -1. **Log in as the superuser**: +### Key Terms - ```bash - psql -h 192.168.49.115 -p 5432 -U homestead -d c77_rbac_test - ``` +1. **Subject**: A user in your system + - Has an `external_id` (usually your Laravel User model's ID) + - Example: User with ID 123 in your Laravel app -2. **Create the extension**: +2. **Role**: A named set of permissions + - Examples: 'admin', 'manager', 'employee' + - Roles are just names - they get their power from features - ```sql - CREATE EXTENSION c77_rbac SCHEMA public; - ``` +3. **Feature**: A specific permission + - Examples: 'view_reports', 'edit_users', 'delete_posts' + - These are what actually get checked by the database - This sets up `c77_rbac_` tables and functions in `public`. +4. **Scope**: The context where a role applies + - Type + ID combination + - Examples: 'department/sales', 'region/north', 'global/all' -3. **Exit**: +5. **Policy**: A database rule that enforces security + - Automatically filters rows based on user permissions + - Invisible to your application code - ```sql - \q - ``` +### How It Works -## Step 2: Set Up Your Application Schema +``` +User (external_id: '123') + → has Role ('manager') + → with Scope ('department/sales') + → Role has Features ('view_reports', 'edit_reports') + → Policy checks these Features + → Database returns only allowed rows +``` -Use a custom schema (e.g., `myapp`) for your tables. +## Installation Walk-through -1. **Log in as your application user** (e.g., `app_user`): +### Step 1: Database Administrator Tasks - ```bash - psql -h 192.168.49.115 -p 5432 -U app_user -d c77_rbac_test - ``` +These steps require PostgreSQL superuser access: -2. **Create the myapp schema**: +```sql +-- 1. Connect as postgres superuser +sudo -u postgres psql - ```sql - CREATE SCHEMA myapp; - ``` +-- 2. Create your database +CREATE DATABASE myapp_db; -3. **Create a test table**: +-- 3. Create application user +CREATE USER myapp_user WITH PASSWORD 'secure_password_here'; - ```sql - CREATE TABLE myapp.orders ( - id SERIAL PRIMARY KEY, - campus TEXT NOT NULL, - amount NUMERIC - ); - ``` +-- 4. Connect to your database +\c myapp_db -4. **Insert test data**: +-- 5. Install the extension +CREATE EXTENSION c77_rbac; - ```sql - INSERT INTO myapp.orders (campus, amount) VALUES ('chicago', 500), ('miami', 1500); - ``` +-- 6. Grant necessary privileges +GRANT CREATE ON DATABASE myapp_db TO myapp_user; +GRANT SELECT ON ALL TABLES IN SCHEMA public TO myapp_user; +GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO myapp_user; +GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO myapp_user; -## Step 3: Apply Row-Level Security (RLS) +-- 7. Set default privileges for future objects +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT SELECT ON TABLES TO myapp_user; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT EXECUTE ON FUNCTIONS TO myapp_user; +ALTER DEFAULT PRIVILEGES IN SCHEMA public + GRANT USAGE, SELECT ON SEQUENCES TO myapp_user; +``` -1. **Apply an RLS policy**: +### Step 2: Verify Installation - ```sql - SELECT public.c77_rbac_apply_policy('myapp.orders', 'view_sales_page', 'campus', 'campus'); - ``` +Connect as your application user: - - `myapp.orders`: Table to secure. - - `view_sales_page`: Required permission. - - `campus`: Scope type. - - `campus`: Column for scope (e.g., `chicago`). +```bash +psql -U myapp_user -d myapp_db -h localhost +``` - A `NOTICE: policy "c77_rbac_policy" ... does not exist` is normal for new tables. +Test the extension: -2. **Check the policy**: +```sql +-- Should return empty results (no subjects yet) +SELECT * FROM public.c77_rbac_subjects; - ```sql - \dp myapp.orders - ``` +-- Should return true +SELECT EXISTS ( + SELECT 1 FROM pg_extension WHERE extname = 'c77_rbac' +) as extension_installed; +``` - Expect `c77_rbac_policy` with: +## Core Functions Explained - ``` - c77_rbac_can_access('view_sales_page'::text, current_setting('c77_rbac.external_id'::text, true), 'campus'::text, campus) - ``` +### 1. c77_rbac_grant_feature(role_name, feature_name) -## Step 4: Assign Roles to Users +**Purpose**: Gives a permission to a role. -Users have an `external_id` (e.g., `'1'`, `'2'`). Admin rights use `global/all`. +**Parameters**: +- `role_name`: The role to grant the feature to (creates if doesn't exist) +- `feature_name`: The permission to grant (creates if doesn't exist) -1. **Assign a sales manager role** (Chicago): +**Example**: +```sql +-- Give 'editor' role the ability to view posts +SELECT public.c77_rbac_grant_feature('editor', 'view_posts'); - ```sql - SELECT public.c77_rbac_assign_subject('1', 'sales_manager', 'campus', 'chicago'); - SELECT public.c77_rbac_grant_feature('sales_manager', 'view_sales_page'); - ``` +-- Give 'editor' role the ability to edit posts +SELECT public.c77_rbac_grant_feature('editor', 'edit_posts'); -2. **Assign an admin role** (all data): +-- Give 'admin' role all post-related features +SELECT public.c77_rbac_grant_feature('admin', 'view_posts'); +SELECT public.c77_rbac_grant_feature('admin', 'edit_posts'); +SELECT public.c77_rbac_grant_feature('admin', 'delete_posts'); +SELECT public.c77_rbac_grant_feature('admin', 'publish_posts'); +``` - ```sql - SELECT public.c77_rbac_assign_subject('999', 'admin', 'global', 'all'); - SELECT public.c77_rbac_grant_feature('admin', 'view_sales_page'); - ``` +**Important**: Admin roles need explicit grants for each feature! - For another admin (e.g., `'2'`): +### 2. c77_rbac_assign_subject(external_id, role_name, scope_type, scope_id) - ```sql - SELECT public.c77_rbac_assign_subject('2', 'admin', 'global', 'all'); - SELECT public.c77_rbac_grant_feature('admin', 'view_sales_page'); - ``` +**Purpose**: Assigns a role to a user with a specific scope. -## Step 5: Test Access +**Parameters**: +- `external_id`: Your application's user ID (as text) +- `role_name`: The role to assign +- `scope_type`: The type of scope (e.g., 'department', 'region', 'global') +- `scope_id`: The specific scope value (e.g., 'sales', 'north', 'all') -1. **Chicago manager**: +**Examples**: +```sql +-- User 123 is an editor in the marketing department +SELECT public.c77_rbac_assign_subject('123', 'editor', 'department', 'marketing'); - ```sql - SET "c77_rbac.external_id" TO '1'; - SELECT * FROM myapp.orders; - ``` +-- User 456 is a manager for the north region +SELECT public.c77_rbac_assign_subject('456', 'manager', 'region', 'north'); - **Expected**: +-- User 1 is a global admin (can access everything) +SELECT public.c77_rbac_assign_subject('1', 'admin', 'global', 'all'); - ``` - id | campus | amount - ----+---------+-------- - 1 | chicago | 500 - ``` +-- User 789 is a viewer with no specific scope +SELECT public.c77_rbac_assign_subject('789', 'viewer', 'none', 'none'); +``` -2. **Admin** (e.g., `'2'`): +### 3. c77_rbac_apply_policy(table_name, feature_name, scope_type, scope_column) - ```sql - SET "c77_rbac.external_id" TO '2'; - SELECT * FROM myapp.orders; - ``` +**Purpose**: Creates a Row-Level Security policy on a table. - **Expected**: +**Parameters**: +- `table_name`: The table to protect (can include schema: 'myschema.posts') +- `feature_name`: The required feature to access rows +- `scope_type`: The scope type to check +- `scope_column`: The column in the table containing the scope value - ``` - id | campus | amount - ----+---------+-------- - 1 | chicago | 500 - 2 | miami | 1500 - ``` +**Examples**: +```sql +-- Protect posts table by department +SELECT public.c77_rbac_apply_policy( + 'posts', -- table name + 'view_posts', -- required feature + 'department', -- scope type + 'department_id' -- column with department ID +); -3. **Unauthorized user**: +-- Protect orders by region +SELECT public.c77_rbac_apply_policy( + 'sales.orders', -- schema-qualified table + 'view_orders', -- required feature + 'region', -- scope type + 'region_code' -- column with region code +); - ```sql - SET "c77_rbac.external_id" TO 'unknown'; - SELECT * FROM myapp.orders; - ``` +-- Protect user profiles (users can only see their own) +SELECT public.c77_rbac_apply_policy( + 'user_profiles', -- table name + 'view_profile', -- required feature + 'user', -- scope type + 'user_id' -- column with user ID +); +``` - **Expected**: +### 4. c77_rbac_can_access(feature_name, external_id, scope_type, scope_id) - ``` - id | campus | amount - ----+--------+-------- - ``` +**Purpose**: Checks if a user has access to a feature with a specific scope. -## Step 6: Use in Your Application +**Parameters**: +- `feature_name`: The feature to check +- `external_id`: The user's ID +- `scope_type`: The scope type +- `scope_id`: The scope value -For Laravel: +**Returns**: Boolean (true/false) -1. **Set user ID**: +**Examples**: +```sql +-- Can user 123 view posts in marketing department? +SELECT public.c77_rbac_can_access('view_posts', '123', 'department', 'marketing'); - ```php - DB::statement("SET c77_rbac.external_id TO '1'"); - ``` +-- Can user 456 edit orders in north region? +SELECT public.c77_rbac_can_access('edit_orders', '456', 'region', 'north'); -2. **Query**: +-- Can user 1 (admin) delete users globally? +SELECT public.c77_rbac_can_access('delete_users', '1', 'global', 'all'); +``` - ```sql - SELECT * FROM myapp.orders; - ``` +### 5. c77_rbac_sync_admin_features() -## Troubleshooting +**Purpose**: Automatically grants all existing features to the 'admin' role. -- **No rows**: Check role (`c77_rbac_assign_subject`) and feature (`c77_rbac_grant_feature`). -- **Policy missing**: Verify `\dp myapp.orders`. Re-run `c77_rbac_apply_policy`. -- **NOTICE messages**: Normal for new tables. -- **Display quirk**: `\dp` may show `campus` instead of `myapp.orders.campus`. This is cosmetic. +**Usage**: +```sql +-- After adding new features, sync them to admin +SELECT public.c77_rbac_sync_admin_features(); +``` -## Notes +**When to use**: +- After adding new features to your system +- During initial setup for admin roles +- As part of deployment scripts -- Use `schema.table` (e.g., `myapp.orders`) with `c77_rbac_apply_policy`. -- `public` is for `c77_rbac_`, Laravel, and third-party packages. Use `myapp` for app tables. -- `c77_rbac_` tables are accessible to all database users. Manage roles responsibly. -- This covers `c77_rbac` only, not `c77_rbac_laravel`. +### 6. c77_rbac_sync_global_admin_features() -For help, ask your database administrator or the `c77_rbac` community. \ No newline at end of file +**Purpose**: Grants all features to any role that has 'global/all' scope. + +**Usage**: +```sql +-- Sync all features to all global admin roles +SELECT public.c77_rbac_sync_global_admin_features(); +``` + +**When to use**: When you have multiple admin-type roles with global scope. + +## Setting Up Your First RBAC System + +Let's build a complete example for a blog application: + +### Step 1: Create Your Schema and Tables + +```sql +-- Create application schema +CREATE SCHEMA blog; + +-- Create tables +CREATE TABLE blog.posts ( + id SERIAL PRIMARY KEY, + title TEXT NOT NULL, + content TEXT, + author_id INTEGER NOT NULL, + department TEXT NOT NULL, + status TEXT DEFAULT 'draft', + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP +); + +CREATE TABLE blog.comments ( + id SERIAL PRIMARY KEY, + post_id INTEGER REFERENCES blog.posts(id), + author_id INTEGER NOT NULL, + content TEXT NOT NULL, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP +); + +-- Insert test data +INSERT INTO blog.posts (title, content, author_id, department, status) VALUES +('Marketing Strategy 2024', 'Content...', 100, 'marketing', 'published'), +('Engineering Best Practices', 'Content...', 200, 'engineering', 'published'), +('Sales Targets Q1', 'Content...', 300, 'sales', 'draft'), +('HR Policy Update', 'Content...', 400, 'hr', 'published'); +``` + +### Step 2: Define Your Permission Structure + +```sql +-- Define features for different roles +-- Viewer role: can only read published posts +SELECT public.c77_rbac_grant_feature('viewer', 'view_published_posts'); + +-- Editor role: can view and edit posts in their department +SELECT public.c77_rbac_grant_feature('editor', 'view_posts'); +SELECT public.c77_rbac_grant_feature('editor', 'edit_posts'); +SELECT public.c77_rbac_grant_feature('editor', 'create_posts'); + +-- Manager role: all editor permissions plus publishing +SELECT public.c77_rbac_grant_feature('manager', 'view_posts'); +SELECT public.c77_rbac_grant_feature('manager', 'edit_posts'); +SELECT public.c77_rbac_grant_feature('manager', 'create_posts'); +SELECT public.c77_rbac_grant_feature('manager', 'publish_posts'); +SELECT public.c77_rbac_grant_feature('manager', 'delete_posts'); + +-- Admin role: everything +SELECT public.c77_rbac_grant_feature('admin', 'view_posts'); +SELECT public.c77_rbac_grant_feature('admin', 'edit_posts'); +SELECT public.c77_rbac_grant_feature('admin', 'create_posts'); +SELECT public.c77_rbac_grant_feature('admin', 'publish_posts'); +SELECT public.c77_rbac_grant_feature('admin', 'delete_posts'); +SELECT public.c77_rbac_grant_feature('admin', 'manage_users'); +``` + +### Step 3: Assign Users to Roles + +```sql +-- Marketing team +SELECT public.c77_rbac_assign_subject('101', 'editor', 'department', 'marketing'); +SELECT public.c77_rbac_assign_subject('102', 'manager', 'department', 'marketing'); + +-- Engineering team +SELECT public.c77_rbac_assign_subject('201', 'editor', 'department', 'engineering'); +SELECT public.c77_rbac_assign_subject('202', 'viewer', 'department', 'engineering'); + +-- Admin user +SELECT public.c77_rbac_assign_subject('1', 'admin', 'global', 'all'); +``` + +### Step 4: Apply Security Policies + +```sql +-- Editors and managers can only see posts in their department +SELECT public.c77_rbac_apply_policy( + 'blog.posts', + 'view_posts', + 'department', + 'department' +); + +-- Anyone can see published posts (you'd implement this differently) +-- For now, let's protect unpublished posts +``` + +### Step 5: Test the Security + +```sql +-- Set user context and test +SET "c77_rbac.external_id" TO '101'; -- Marketing editor + +-- Should only see marketing posts +SELECT * FROM blog.posts; + +-- Switch to admin +SET "c77_rbac.external_id" TO '1'; + +-- Should see all posts +SELECT * FROM blog.posts; +``` + +## Laravel Integration Guide + +### Step 1: Configure Database Connection + +In `.env`: +```ini +DB_CONNECTION=pgsql +DB_HOST=127.0.0.1 +DB_PORT=5432 +DB_DATABASE=myapp_db +DB_USERNAME=myapp_user +DB_PASSWORD=your_secure_password +``` + +### Step 2: Create Middleware + +Create `app/Http/Middleware/SetRbacContext.php`: + +```php + [ + // ... other middleware + \App\Http\Middleware\SetRbacContext::class, + ], + + 'api' => [ + // ... other middleware + \App\Http\Middleware\SetRbacContext::class, + ], +]; +``` + +### Step 3: Create RBAC Service + +Create `app/Services/RbacService.php`: + +```php +allowed ?? false; + }); + } + + /** + * Assign a role to a user + */ + public function assignRole(int $userId, string $role, string $scopeType, string $scopeId): void + { + DB::statement( + 'SELECT public.c77_rbac_assign_subject(?, ?, ?, ?)', + [(string) $userId, $role, $scopeType, $scopeId] + ); + + // Clear cache for this user + Cache::tags(["rbac:user:{$userId}"])->flush(); + } + + /** + * Grant a feature to a role + */ + public function grantFeature(string $role, string $feature): void + { + DB::statement( + 'SELECT public.c77_rbac_grant_feature(?, ?)', + [$role, $feature] + ); + } + + /** + * Apply RLS policy to a table + */ + public function applyPolicy(string $table, string $feature, string $scopeType, string $scopeColumn): void + { + DB::statement( + 'SELECT public.c77_rbac_apply_policy(?, ?, ?, ?)', + [$table, $feature, $scopeType, $scopeColumn] + ); + } + + /** + * Sync all features to admin roles + */ + public function syncAdminFeatures(): void + { + DB::statement('SELECT public.c77_rbac_sync_admin_features()'); + } + + /** + * Get all roles for a user + */ + public function getUserRoles(int $userId): array + { + return DB::select(' + SELECT r.name as role, sr.scope_type, sr.scope_id + FROM public.c77_rbac_subjects s + JOIN public.c77_rbac_subject_roles sr ON s.subject_id = sr.subject_id + JOIN public.c77_rbac_roles r ON sr.role_id = r.role_id + WHERE s.external_id = ? + ', [(string) $userId]); + } + + /** + * Get all features for a role + */ + public function getRoleFeatures(string $role): array + { + return DB::select(' + SELECT f.name as feature + 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 + WHERE r.name = ? + ', [$role]); + } +} +``` + +### Step 4: Create Migrations + +Create base migration for RBAC setup: + +```php +rbac = new RbacService(); + } + + public function up() + { + // Define your application's roles and features + $roles = [ + 'admin' => [ + 'manage_users', 'view_all_data', 'edit_all_data', + 'delete_all_data', 'view_reports', 'export_data' + ], + 'manager' => [ + 'view_reports', 'edit_department_data', + 'approve_content', 'export_data' + ], + 'editor' => [ + 'create_content', 'edit_content', 'view_content' + ], + 'viewer' => [ + 'view_content', 'view_reports' + ] + ]; + + // Create roles and grant features + foreach ($roles as $role => $features) { + foreach ($features as $feature) { + $this->rbac->grantFeature($role, $feature); + } + } + + // Sync admin features + $this->rbac->syncAdminFeatures(); + } + + public function down() + { + // Note: This doesn't remove the roles/features + // You might want to add cleanup logic here + } +} +``` + +Migration for applying RLS to tables: + +```php +rbac = new RbacService(); + } + + public function up() + { + // Add department column if it doesn't exist + if (!Schema::hasColumn('posts', 'department_id')) { + Schema::table('posts', function (Blueprint $table) { + $table->unsignedInteger('department_id')->nullable(); + }); + } + + // Apply RLS policy + $this->rbac->applyPolicy( + 'posts', // table + 'view_content', // required feature + 'department', // scope type + 'department_id' // scope column + ); + } + + public function down() + { + // Remove RLS policy + DB::statement('DROP POLICY IF EXISTS c77_rbac_policy ON posts'); + DB::statement('ALTER TABLE posts DISABLE ROW LEVEL SECURITY'); + } +} +``` + +### Step 5: User Model Integration + +Add methods to your User model: + +```php +assignRole($this->id, $role, $scopeType, $scopeId); + } + + /** + * Check if user has permission + */ + public function can($feature, $scopeType = null, $scopeId = null): bool + { + // If using Laravel's built-in authorization + if (is_string($feature) && strpos($feature, ':') !== false) { + [$feature, $scope] = explode(':', $feature); + [$scopeType, $scopeId] = explode('/', $scope); + } + + return self::getRbacService()->can($feature, $scopeType ?? 'global', $scopeId ?? 'all'); + } + + /** + * Get all roles for this user + */ + public function getRoles(): array + { + return self::getRbacService()->getUserRoles($this->id); + } + + /** + * Check if user has a specific role + */ + public function hasRole(string $role, ?string $scopeType = null, ?string $scopeId = null): bool + { + $roles = $this->getRoles(); + + foreach ($roles as $userRole) { + if ($userRole->role === $role) { + if ($scopeType === null || $userRole->scope_type === $scopeType) { + if ($scopeId === null || $userRole->scope_id === $scopeId) { + return true; + } + } + } + } + + return false; + } + + /** + * Check if user is admin + */ + public function isAdmin(): bool + { + return $this->hasRole('admin', 'global', 'all'); + } +} +``` + +### Step 6: Controller Integration + +Example controller using RBAC: + +```php +rbac = $rbac; + } + + public function index() + { + // Posts are automatically filtered by RLS + $posts = Post::all(); + + return view('posts.index', compact('posts')); + } + + public function create() + { + // Check if user can create posts in their department + if (!auth()->user()->can('create_content:department/' . auth()->user()->department_id)) { + abort(403, 'Unauthorized'); + } + + return view('posts.create'); + } + + public function edit(Post $post) + { + // Check if user can edit this specific post + if (!$this->rbac->can('edit_content', 'department', $post->department_id)) { + abort(403, 'Unauthorized'); + } + + return view('posts.edit', compact('post')); + } + + public function destroy(Post $post) + { + // Only managers and admins can delete + if (!$this->rbac->can('delete_content', 'department', $post->department_id)) { + abort(403, 'Unauthorized'); + } + + $post->delete(); + + return redirect()->route('posts.index'); + } +} +``` + +### Step 7: Blade Templates + +Use in Blade templates: + +```blade +@if(auth()->user()->can('create_content:department/' . auth()->user()->department_id)) + Create Post +@endif + +@foreach($posts as $post) +
+

{{ $post->title }}

+

{{ $post->content }}

+ + @if(auth()->user()->can('edit_content:department/' . $post->department_id)) + Edit + @endif + + @if(auth()->user()->can('delete_content:department/' . $post->department_id)) +
+ @csrf + @method('DELETE') + +
+ @endif +
+@endforeach +``` + +### Step 8: API Authentication + +For API routes, ensure the context is set: + +```php +middleware(function ($request, $next) { + if ($request->user()) { + DB::statement('SET "c77_rbac.external_id" TO ?', [$request->user()->id]); + } + + return $next($request); + }); + } +} +``` + +## Common Patterns and Examples + +### Pattern 1: Department-Based Access + +```php +// Migration +public function up() +{ + // Define department roles + $this->rbac->grantFeature('dept_manager', 'view_dept_data'); + $this->rbac->grantFeature('dept_manager', 'edit_dept_data'); + $this->rbac->grantFeature('dept_manager', 'approve_dept_requests'); + + $this->rbac->grantFeature('dept_member', 'view_dept_data'); + $this->rbac->grantFeature('dept_member', 'create_requests'); + + // Apply policy to department data + $this->rbac->applyPolicy( + 'department_data', + 'view_dept_data', + 'department', + 'dept_id' + ); +} + +// Assigning users +$user->assignRole('dept_manager', 'department', 'sales'); +$user->assignRole('dept_member', 'department', 'engineering'); +``` + +### Pattern 2: Multi-Tenant Application + +```php +// Migration for tenant isolation +public function up() +{ + // Define tenant roles + $this->rbac->grantFeature('tenant_admin', 'manage_tenant'); + $this->rbac->grantFeature('tenant_user', 'view_tenant_data'); + + // Apply policies to all tenant tables + $tables = ['accounts', 'projects', 'invoices', 'users']; + + foreach ($tables as $table) { + $this->rbac->applyPolicy( + "tenants.{$table}", + 'view_tenant_data', + 'tenant', + 'tenant_id' + ); + } +} + +// Middleware for tenant context +public function handle($request, Closure $next) +{ + $tenant = $request->user()->tenant; + + // Set tenant context + DB::statement('SET "app.current_tenant" TO ?', [$tenant->id]); + DB::statement('SET "c77_rbac.external_id" TO ?', [$request->user()->id]); + + return $next($request); +} +``` + +### Pattern 3: Hierarchical Permissions + +```php +// Regional hierarchy: Global > Region > Branch > Store +public function setupHierarchy() +{ + // Global admin sees everything + $this->rbac->grantFeature('global_admin', 'view_all_stores'); + $this->rbac->assignRole($userId, 'global_admin', 'global', 'all'); + + // Regional manager sees their region + $this->rbac->grantFeature('regional_manager', 'view_region_stores'); + $this->rbac->assignRole($userId, 'regional_manager', 'region', 'west'); + + // Branch manager sees their branch + $this->rbac->grantFeature('branch_manager', 'view_branch_stores'); + $this->rbac->assignRole($userId, 'branch_manager', 'branch', 'west-1'); + + // Store manager sees their store + $this->rbac->grantFeature('store_manager', 'view_store_data'); + $this->rbac->assignRole($userId, 'store_manager', 'store', 'west-1-a'); +} +``` + +### Pattern 4: Time-Based Permissions (Advanced) + +```php +// Create a scheduled job to manage temporary permissions +class ManageTemporaryPermissions extends Command +{ + public function handle() + { + // Remove expired temporary roles + DB::statement(" + DELETE FROM public.c77_rbac_subject_roles + WHERE (scope_type, scope_id) IN ( + SELECT 'temporary', id::text + FROM temporary_permissions + WHERE expires_at < NOW() + ) + "); + + // Add new temporary roles + $newTemp = TemporaryPermission::where('starts_at', '<=', now()) + ->where('applied', false) + ->get(); + + foreach ($newTemp as $temp) { + $this->rbac->assignRole( + $temp->user_id, + $temp->role, + 'temporary', + $temp->id + ); + + $temp->update(['applied' => true]); + } + } +} +``` + +## Advanced Usage + +### Custom Scopes + +You can create any scope type that makes sense for your application: + +```php +// Example: Project-based access +$this->rbac->assignRole($userId, 'project_lead', 'project', $projectId); +$this->rbac->assignRole($userId, 'developer', 'project', $projectId); + +// Example: Customer-based access for support +$this->rbac->assignRole($userId, 'support_agent', 'customer', $customerId); +$this->rbac->assignRole($userId, 'account_manager', 'customer_tier', 'platinum'); + +// Example: Geographic access +$this->rbac->assignRole($userId, 'country_manager', 'country', 'US'); +$this->rbac->assignRole($userId, 'city_coordinator', 'city', 'NYC'); +``` + +### Dynamic Policy Application + +Create a service to dynamically apply policies based on your schema: + +```php +class DynamicPolicyService +{ + protected RbacService $rbac; + + public function applyPoliciesForModel(string $modelClass) + { + $model = new $modelClass; + $table = $model->getTable(); + + // Get policy configuration for this model + $policies = config("rbac.policies.{$modelClass}", []); + + foreach ($policies as $policy) { + $this->rbac->applyPolicy( + $table, + $policy['feature'], + $policy['scope_type'], + $policy['scope_column'] + ); + } + } + + public function applyAllPolicies() + { + $models = config('rbac.protected_models', []); + + foreach ($models as $model) { + $this->applyPoliciesForModel($model); + } + } +} + +// Config file: config/rbac.php +return [ + 'protected_models' => [ + \App\Models\Post::class, + \App\Models\Document::class, + \App\Models\Invoice::class, + ], + + 'policies' => [ + \App\Models\Post::class => [ + [ + 'feature' => 'view_posts', + 'scope_type' => 'department', + 'scope_column' => 'department_id', + ], + ], + \App\Models\Invoice::class => [ + [ + 'feature' => 'view_invoices', + 'scope_type' => 'customer', + 'scope_column' => 'customer_id', + ], + [ + 'feature' => 'edit_invoices', + 'scope_type' => 'department', + 'scope_column' => 'created_by_dept', + ], + ], + ], +]; +``` + +### Complex Permission Checks + +For complex business rules that go beyond simple RBAC: + +```php +class AdvancedPermissionService +{ + protected RbacService $rbac; + + public function canApproveExpense(User $user, Expense $expense): bool + { + // Basic RBAC check + if (!$this->rbac->can('approve_expenses', 'department', $expense->department_id)) { + return false; + } + + // Additional business rules + if ($expense->amount > 10000 && !$user->hasRole('senior_manager')) { + return false; + } + + // Check spending limits + $monthlySpent = $this->getMonthlySpending($user->department_id); + if ($monthlySpent + $expense->amount > $user->department->budget_limit) { + return false; + } + + return true; + } + + public function canEditDocument(User $user, Document $document): bool + { + // Owner can always edit their draft documents + if ($document->author_id === $user->id && $document->status === 'draft') { + return true; + } + + // Editors can edit within their scope + if ($this->rbac->can('edit_documents', 'department', $document->department_id)) { + return true; + } + + // Admins can edit anything + if ($user->hasRole('admin', 'global', 'all')) { + return true; + } + + return false; + } +} +``` + +### Audit Logging + +Track all permission changes: + +```php +class RbacAuditService +{ + public function logRoleAssignment(int $userId, string $role, string $scopeType, string $scopeId, ?int $assignedBy = null) + { + DB::table('rbac_audit_log')->insert([ + 'action' => 'role_assigned', + 'user_id' => $userId, + 'details' => json_encode([ + 'role' => $role, + 'scope_type' => $scopeType, + 'scope_id' => $scopeId, + ]), + 'performed_by' => $assignedBy ?? auth()->id(), + 'created_at' => now(), + ]); + } + + public function logPermissionCheck(int $userId, string $feature, string $scopeType, string $scopeId, bool $granted) + { + // Only log denied permissions or critical features + if ($granted && !$this->isCriticalFeature($feature)) { + return; + } + + DB::table('rbac_audit_log')->insert([ + 'action' => 'permission_checked', + 'user_id' => $userId, + 'details' => json_encode([ + 'feature' => $feature, + 'scope_type' => $scopeType, + 'scope_id' => $scopeId, + 'granted' => $granted, + ]), + 'created_at' => now(), + ]); + } + + protected function isCriticalFeature(string $feature): bool + { + $critical = ['delete_users', 'manage_billing', 'export_all_data']; + return in_array($feature, $critical); + } +} +``` + +### Testing RBAC + +Create comprehensive tests: + +```php +class RbacTest extends TestCase +{ + protected RbacService $rbac; + + protected function setUp(): void + { + parent::setUp(); + $this->rbac = app(RbacService::class); + + // Clean up any existing test data + DB::statement("DELETE FROM public.c77_rbac_subjects WHERE external_id LIKE 'test_%'"); + } + + public function test_department_isolation() + { + // Create test users + $salesUser = User::factory()->create(['id' => 1001]); + $engineeringUser = User::factory()->create(['id' => 1002]); + + // Assign roles + $this->rbac->assignRole($salesUser->id, 'editor', 'department', 'sales'); + $this->rbac->assignRole($engineeringUser->id, 'editor', 'department', 'engineering'); + + // Create test posts + $salesPost = Post::factory()->create(['department_id' => 'sales']); + $engineeringPost = Post::factory()->create(['department_id' => 'engineering']); + + // Test as sales user + $this->actingAs($salesUser); + $visiblePosts = Post::all(); + + $this->assertTrue($visiblePosts->contains($salesPost)); + $this->assertFalse($visiblePosts->contains($engineeringPost)); + } + + public function test_admin_sees_everything() + { + $admin = User::factory()->create(['id' => 1003]); + $this->rbac->assignRole($admin->id, 'admin', 'global', 'all'); + $this->rbac->syncAdminFeatures(); + + // Create posts in different departments + $posts = [ + Post::factory()->create(['department_id' => 'sales']), + Post::factory()->create(['department_id' => 'engineering']), + Post::factory()->create(['department_id' => 'hr']), + ]; + + $this->actingAs($admin); + $visiblePosts = Post::all(); + + foreach ($posts as $post) { + $this->assertTrue($visiblePosts->contains($post)); + } + } + + public function test_permission_caching() + { + $user = User::factory()->create(); + $this->rbac->assignRole($user->id, 'editor', 'department', 'sales'); + + // First call should hit database + $startQueries = DB::getQueryLog(); + $canEdit = $this->rbac->can('edit_posts', 'department', 'sales'); + $endQueries = DB::getQueryLog(); + + $this->assertTrue(count($endQueries) > count($startQueries)); + + // Second call should use cache + $startQueries = DB::getQueryLog(); + $canEdit2 = $this->rbac->can('edit_posts', 'department', 'sales'); + $endQueries = DB::getQueryLog(); + + $this->assertEquals(count($startQueries), count($endQueries)); + $this->assertEquals($canEdit, $canEdit2); + } +} +``` + +## Troubleshooting Guide + +### Problem: No Data Returned + +**Symptoms**: Queries return empty results when data should be visible. + +**Diagnosis Steps**: + +1. Check if the session variable is set: +```sql +SELECT current_setting('c77_rbac.external_id', true); +``` + +2. Verify the user has the correct role: +```sql +SELECT s.external_id, r.name, sr.scope_type, sr.scope_id +FROM public.c77_rbac_subjects s +JOIN public.c77_rbac_subject_roles sr ON s.subject_id = sr.subject_id +JOIN public.c77_rbac_roles r ON sr.role_id = r.role_id +WHERE s.external_id = 'your_user_id'; +``` + +3. Check if the role has the required feature: +```sql +SELECT r.name as role, f.name as feature +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 +WHERE r.name = 'your_role'; +``` + +4. Verify the policy is applied correctly: +```sql +SELECT * FROM pg_policies +WHERE tablename = 'your_table'; +``` + +5. Test the access function directly: +```sql +SELECT public.c77_rbac_can_access('feature', 'user_id', 'scope_type', 'scope_id'); +``` + +**Common Solutions**: +- Ensure middleware is setting the external_id +- Check for typos in feature names +- Verify scope values match exactly +- Remember admin roles need explicit feature grants + +### Problem: Performance Issues + +**Symptoms**: Slow queries on tables with RLS policies. + +**Diagnosis**: +```sql +EXPLAIN ANALYZE SELECT * FROM your_table; +``` + +**Solutions**: + +1. Add indexes on scope columns: +```sql +CREATE INDEX idx_posts_department_id ON posts(department_id); +``` + +2. Use connection pooling carefully: +```php +// In database.php +'pgsql' => [ + 'sticky' => true, // Reuse connections + // ... other settings +], +``` + +3. Cache permission checks: +```php +public function can($feature, $scopeType, $scopeId): bool +{ + return Cache::tags(['rbac', "user:{$this->id}"])->remember( + "can:{$feature}:{$scopeType}:{$scopeId}", + 300, + fn() => $this->checkPermission($feature, $scopeType, $scopeId) + ); +} +``` + +### Problem: Middleware Not Working + +**Symptoms**: User context not set, permissions not enforced. + +**Diagnosis**: +```php +// Add to middleware +\Log::info('RBAC Middleware', [ + 'user_id' => Auth::id(), + 'external_id' => DB::selectOne("SELECT current_setting('c77_rbac.external_id', true) as id")->id +]); +``` + +**Solutions**: +1. Check middleware registration order +2. Ensure auth middleware runs before RBAC middleware +3. Handle API authentication separately + +### Problem: Admin Can't Access Data + +**Symptoms**: Admin users with global/all scope can't see data. + +**Solution**: +```sql +-- Sync all features to admin +SELECT public.c77_rbac_sync_admin_features(); + +-- Or manually grant specific features +SELECT public.c77_rbac_grant_feature('admin', 'specific_feature'); +``` + +## Performance Considerations + +### 1. Index Strategy + +Always index columns used in RLS policies: + +```sql +-- For department-based access +CREATE INDEX idx_table_department ON table_name(department_id); + +-- For user-based access +CREATE INDEX idx_table_user ON table_name(user_id); + +-- For composite scopes +CREATE INDEX idx_table_composite ON table_name(department_id, status); +``` + +### 2. Query Optimization + +Use EXPLAIN ANALYZE to understand query performance: + +```sql +-- Before applying RLS +EXPLAIN ANALYZE SELECT * FROM posts WHERE department_id = 'sales'; + +-- After applying RLS +SET "c77_rbac.external_id" TO '123'; +EXPLAIN ANALYZE SELECT * FROM posts; +``` + +### 3. Caching Strategy + +Implement multi-level caching: + +```php +class CachedRbacService extends RbacService +{ + public function can(string $feature, string $scopeType, string $scopeId): bool + { + // L1: In-memory cache (request lifecycle) + static $cache = []; + $key = "{$feature}:{$scopeType}:{$scopeId}:" . Auth::id(); + + if (isset($cache[$key])) { + return $cache[$key]; + } + + // L2: Redis/Memcached cache + $result = Cache::remember("rbac:{$key}", 300, function () use ($feature, $scopeType, $scopeId) { + return parent::can($feature, $scopeType, $scopeId); + }); + + $cache[$key] = $result; + return $result; + } +} +``` + +### 4. Batch Operations + +For bulk operations, temporarily switch to a privileged user: + +```php +public function bulkImport(array $data) +{ + // Save current user + $currentUser = DB::selectOne("SELECT current_setting('c77_rbac.external_id', true) as id")->id; + + try { + // Switch to system user with full access + DB::statement('SET "c77_rbac.external_id" TO ?', ['system']); + + // Perform bulk operations + DB::transaction(function () use ($data) { + foreach ($data as $record) { + Model::create($record); + } + }); + } finally { + // Restore original user + DB::statement('SET "c77_rbac.external_id" TO ?', [$currentUser]); + } +} +``` + +## Security Best Practices + +### 1. Input Validation + +Always validate scope parameters: + +```php +public function assignRole(Request $request) +{ + $request->validate([ + 'user_id' => 'required|integer|exists:users,id', + 'role' => 'required|string|in:admin,manager,editor,viewer', + 'scope_type' => 'required|string|in:global,department,region,project', + 'scope_id' => 'required|string|max:50', + ]); + + // Sanitize scope_id to prevent SQL injection + $scopeId = preg_replace('/[^a-zA-Z0-9_-]/', '', $request->scope_id); + + $this->rbac->assignRole( + $request->user_id, + $request->role, + $request->scope_type, + $scopeId + ); +} +``` + +### 2. Principle of Least Privilege + +Start with minimal permissions: + +```php +// Default role for new users +public function registered(User $user) +{ + // Give only viewing permissions by default + $user->assignRole('viewer', 'department', $user->department_id); +} + +// Elevate privileges only when needed +public function promoteToEditor(User $user) +{ + // Remove viewer role first + $this->rbac->removeRole($user->id, 'viewer', 'department', $user->department_id); + + // Add editor role + $user->assignRole('editor', 'department', $user->department_id); +} +``` + +### 3. Session Security + +Clean up sessions properly: + +```php +class SessionCleanupMiddleware +{ + public function handle($request, Closure $next) + { + $response = $next($request); + + // Always reset on response + DB::statement('RESET "c77_rbac.external_id"'); + + return $response; + } + + public function terminate($request, $response) + { + // Extra cleanup for long-running processes + DB::statement('RESET ALL'); + } +} +``` + +### 4. Audit Critical Operations + +Log all permission changes and critical accesses: + +```php +class AuditableRbacService extends RbacService +{ + public function assignRole(int $userId, string $role, string $scopeType, string $scopeId): void + { + parent::assignRole($userId, $role, $scopeType, $scopeId); + + activity() + ->performedOn(User::find($userId)) + ->causedBy(auth()->user()) + ->withProperties([ + 'role' => $role, + 'scope_type' => $scopeType, + 'scope_id' => $scopeId, + ]) + ->log('Role assigned'); + } + + public function can(string $feature, string $scopeType, string $scopeId): bool + { + $result = parent::can($feature, $scopeType, $scopeId); + + // Log only critical features or denials + if (!$result || $this->isCriticalFeature($feature)) { + activity() + ->causedBy(auth()->user()) + ->withProperties([ + 'feature' => $feature, + 'scope_type' => $scopeType, + 'scope_id' => $scopeId, + 'granted' => $result, + ]) + ->log('Permission check'); + } + + return $result; + } +} +``` + +### 5. Regular Security Reviews + +Create a command to audit your RBAC setup: + +```php +class AuditRbacCommand extends Command +{ + protected $signature = 'rbac:audit'; + + public function handle() + { + $this->info('RBAC Security Audit'); + + // Check for users with multiple admin roles + $multiAdmins = DB::select(" + SELECT s.external_id, COUNT(*) as admin_roles + FROM public.c77_rbac_subjects s + JOIN public.c77_rbac_subject_roles sr ON s.subject_id = sr.subject_id + JOIN public.c77_rbac_roles r ON sr.role_id = r.role_id + WHERE r.name = 'admin' + GROUP BY s.external_id + HAVING COUNT(*) > 1 + "); + + if (count($multiAdmins) > 0) { + $this->warn('Users with multiple admin roles: ' . count($multiAdmins)); + } + + // Check for overly permissive policies + $policies = DB::select(" + SELECT schemaname, tablename, policyname, qual + FROM pg_policies + WHERE policyname = 'c77_rbac_policy' + "); + + foreach ($policies as $policy) { + if (strpos($policy->qual, 'true') !== false) { + $this->error("Potentially overly permissive policy on {$policy->schemaname}.{$policy->tablename}"); + } + } + + // Check for orphaned roles + $orphanedRoles = DB::select(" + SELECT r.name + FROM public.c77_rbac_roles r + LEFT JOIN public.c77_rbac_subject_roles sr ON r.role_id = sr.role_id + WHERE sr.role_id IS NULL + "); + + if (count($orphanedRoles) > 0) { + $this->warn('Orphaned roles (no users): ' . count($orphanedRoles)); + } + + $this->info('Audit complete'); + } +} +``` + +## Summary + +The c77_rbac extension provides a powerful, database-centric approach to authorization. Key takeaways: + +1. **Database-Level Security**: RLS policies ensure consistent access control +2. **Flexible Scoping**: Support for any type of organizational structure +3. **Framework Agnostic**: Works with any application framework +4. **Performance**: Optimized with indexes and caching strategies +5. **Maintainable**: Clear separation of concerns between features, roles, and policies + +Remember to: +- Always grant specific features to admin roles +- Use caching for permission checks +- Index columns used in policies +- Audit your RBAC setup regularly +- Clean up database sessions properly + +With proper setup and maintenance, c77_rbac provides enterprise-grade authorization that scales with your application. \ No newline at end of file diff --git a/c77_rbac--1.0.sql b/c77_rbac--1.0.sql index 373dfba..31d5be3 100644 --- a/c77_rbac--1.0.sql +++ b/c77_rbac--1.0.sql @@ -255,6 +255,72 @@ GRANT EXECUTE ON FUNCTION public.c77_rbac_apply_policy(TEXT, TEXT, TEXT, TEXT) TO PUBLIC; +-- Function to remove all RLS policies and prepare for extension removal +CREATE OR REPLACE FUNCTION public.c77_rbac_remove_all_policies() + RETURNS void AS $$ +DECLARE + policy_record RECORD; + table_count INTEGER := 0; +BEGIN + -- Find and remove all c77_rbac policies + FOR policy_record IN + SELECT schemaname, tablename, policyname + FROM pg_policies + WHERE policyname = 'c77_rbac_policy' + LOOP + EXECUTE format('DROP POLICY IF EXISTS %I ON %I.%I', + policy_record.policyname, + policy_record.schemaname, + policy_record.tablename); + + -- Optionally disable RLS on the table + EXECUTE format('ALTER TABLE %I.%I DISABLE ROW LEVEL SECURITY', + policy_record.schemaname, + policy_record.tablename); + + table_count := table_count + 1; + RAISE NOTICE 'Removed policy from %.%', policy_record.schemaname, policy_record.tablename; + END LOOP; + + RAISE NOTICE 'Removed policies from % tables', table_count; + RAISE NOTICE 'You can now run: DROP EXTENSION c77_rbac CASCADE;'; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; + +-- More comprehensive cleanup function that also clears data +CREATE OR REPLACE FUNCTION public.c77_rbac_cleanup_for_removal( + p_remove_data BOOLEAN DEFAULT false +) + RETURNS void AS $$ +DECLARE + policy_record RECORD; + table_count INTEGER := 0; +BEGIN + -- First remove all policies + PERFORM public.c77_rbac_remove_all_policies(); + + -- Optionally clear all RBAC data + IF p_remove_data THEN + -- Clear in correct order due to foreign keys + DELETE FROM public.c77_rbac_subject_roles; + DELETE FROM public.c77_rbac_role_features; + DELETE FROM public.c77_rbac_subjects; + DELETE FROM public.c77_rbac_roles; + DELETE FROM public.c77_rbac_features; + + RAISE NOTICE 'Cleared all RBAC data'; + END IF; + + RAISE NOTICE 'Cleanup complete. You can now run: DROP EXTENSION c77_rbac CASCADE;'; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; + +-- Grant execute permissions +GRANT EXECUTE ON FUNCTION + public.c77_rbac_remove_all_policies(), + public.c77_rbac_cleanup_for_removal(BOOLEAN) + TO PUBLIC; + -- Grant table permissions with more restrictions GRANT SELECT ON public.c77_rbac_subjects, @@ -271,4 +337,61 @@ REVOKE INSERT, UPDATE, DELETE ON public.c77_rbac_features, public.c77_rbac_subject_roles, public.c77_rbac_role_features - FROM PUBLIC; \ No newline at end of file + FROM PUBLIC; + +-- Function to show what depends on c77_rbac +-- Fixed version of the dependencies function +CREATE OR REPLACE FUNCTION public.c77_rbac_show_dependencies() + RETURNS TABLE( + dependency_type TEXT, + schema_name TEXT, + object_name TEXT, + details TEXT + ) AS $$ +BEGIN + RETURN QUERY + SELECT * FROM ( + -- Find policies + SELECT + 'POLICY'::TEXT as dependency_type, + schemaname::TEXT as schema_name, + tablename::TEXT as object_name, + policyname::TEXT as details + FROM pg_policies + WHERE policyname = 'c77_rbac_policy' + + UNION ALL + + -- Find tables with RLS enabled + SELECT + 'RLS_ENABLED'::TEXT as dependency_type, + schemaname::TEXT as schema_name, + tablename::TEXT as object_name, + 'Row Level Security is enabled'::TEXT as details + FROM pg_tables + WHERE rowsecurity = true + AND (schemaname, tablename) IN ( + SELECT schemaname, tablename + FROM pg_policies + WHERE policyname = 'c77_rbac_policy' + ) + + UNION ALL + + -- Find stored procedures that might use c77_rbac functions + SELECT DISTINCT + 'FUNCTION'::TEXT as dependency_type, + n.nspname::TEXT as schema_name, + p.proname::TEXT as object_name, + 'May reference c77_rbac functions'::TEXT as details + FROM pg_proc p + JOIN pg_namespace n ON p.pronamespace = n.oid + WHERE p.prosrc LIKE '%c77_rbac%' + AND n.nspname NOT IN ('pg_catalog', 'information_schema') + AND p.proname NOT LIKE 'c77_rbac%' + ) AS dependencies + ORDER BY dependency_type, schema_name, object_name; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; + +GRANT EXECUTE ON FUNCTION public.c77_rbac_show_dependencies() TO PUBLIC;