8.8 KiB
c77_rbac
A PostgreSQL extension for Role-Based Access Control (RBAC) with Row-Level Security (RLS) integration. Designed to be agnostic, c77_rbac
works with any application framework, providing fine-grained, database-driven authorization. The companion extension c77_rbac_laravel
integrates seamlessly with Laravel applications.
Features
- Agnostic RBAC Core: Manage roles, features, and subjects with flexible
external_id
(TEXT) for compatibility with any system (Laravel, Django, Rails, etc.). - Row-Level Security (RLS): Enforce access control directly in PostgreSQL using RLS policies tied to RBAC rules.
- Scoped Permissions: Assign roles with scope (e.g.,
campus/chicago
) for granular control. - Admin Role Support: Optional
admin
role bypasses scope restrictions for universal access. - Laravel Integration:
c77_rbac_laravel
maps Laravel user IDs to RBAC subjects and sets session variables via middleware. - Secure Design: Uses
SECURITY DEFINER
functions to protect RBAC metadata, requiring no direct table access for application users.
Requirements
- PostgreSQL 13 or later (tested on 17).
- Superuser access to install extensions.
- Application user (e.g.,
app_user
) with permissions to create tables and execute functions.
Installation
Step 1: Install Extensions
Copy the extension files to your PostgreSQL extension directory (e.g., /usr/share/postgresql/17/extension/
):
sudo cp c77_rbac--1.0.sql c77_rbac.control /usr/share/postgresql/17/extension/
sudo cp c77_rbac_laravel--1.0.sql c77_rbac_laravel.control /usr/share/postgresql/17/extension/
Step 2: Create a Database
-- As a superuser (e.g., postgres)
CREATE DATABASE myapp;
GRANT ALL ON DATABASE myapp TO app_user;
Step 3: Enable Extensions
Connect to your database as app_user
:
psql -d myapp -U app_user -h localhost
CREATE EXTENSION c77_rbac;
CREATE EXTENSION c77_rbac_laravel; -- Optional, for Laravel integration
Database Schema
Core Tables (c77_rbac
)
c77_rbac_subjects
: Tracks entities (users, systems) with a uniqueexternal_id
(TEXT),scope_type
, andscope_id
.c77_rbac_roles
: Defines roles (e.g.,sales_manager
).c77_rbac_features
: Defines permissions (e.g.,view_sales_page
).c77_rbac_subject_roles
: Assigns roles to subjects with optional scope.c77_rbac_role_features
: Grants features to roles.
Core Functions
c77_rbac_assign_subject(p_external_id, p_role_name, p_scope_type, p_scope_id)
: Assign a role to a subject with scope.c77_rbac_grant_feature(p_role_name, p_feature_name)
: Grant a feature to a role.c77_rbac_can_access(p_feature_name, p_external_id, p_scope_type, p_scope_id)
: Check if a subject has access to a feature within a scope.
Laravel Functions (c77_rbac_laravel
)
c77_rbac_laravel_auth_id()
: Retrievesexternal_id
from session variable (c77_rbac.external_id
).c77_rbac_laravel_assign_user(p_laravel_id, p_role_name, p_scope_type, p_scope_id)
: Assigns a Laravel user ID to a role.
Usage
Example: Basic Setup
-- As app_user
-- Assign a user (external_id = '1') to sales_manager role for chicago campus
SELECT public.c77_rbac_laravel_assign_user(1, 'sales_manager', 'campus', 'chicago');
-- Grant view_sales_page feature to sales_manager
SELECT public.c77_rbac_grant_feature('sales_manager', 'view_sales_page');
-- Create a sales table with RLS
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);
ALTER TABLE public.sales ENABLE ROW LEVEL SECURITY;
CREATE POLICY rbac_policy ON public.sales FOR ALL TO PUBLIC USING (
public.c77_rbac_can_access('view_sales_page', public.c77_rbac_laravel_auth_id(), 'campus', campus)
);
-- Test as user 1
SET "c77_rbac.external_id" TO '1';
SELECT * FROM public.sales;
Expected Output:
id | campus | amount
----+---------+--------
1 | chicago | 1000
(1 row)
Example: Admin Role
-- Assign admin role to user 999 (no scope restrictions)
SELECT public.c77_rbac_laravel_assign_user(999, 'admin', NULL, NULL);
SELECT public.c77_rbac_grant_feature('admin', 'view_sales_page');
-- Test as admin
SET "c77_rbac.external_id" TO '999';
SELECT * FROM public.sales;
Expected Output:
id | campus | amount
----+---------+--------
1 | chicago | 1000
2 | miami | 2000
(2 rows)
Laravel Integration
When ready to use with Laravel, configure your .env
:
DB_CONNECTION=pgsql
DB_HOST=localhost
DB_PORT=5432
DB_DATABASE=myapp
DB_USERNAME=app_user
DB_PASSWORD=your_password
Middleware
Add middleware to set external_id
:
// app/Http/Middleware/SetRbacExternalId.php
namespace App\Http\Middleware;
use Closure;
use Illuminate\Support\Facades\Auth;
use Illuminate\Support\Facades\DB;
class SetRbacExternalId
{
public function handle($request, Closure $next)
{
if (Auth::check()) {
DB::statement('SET "c77_rbac.external_id" TO ?', [Auth::id()]);
}
return $next($request);
}
}
Register in app/Http/Kernel.php
:
protected $middlewareGroups = [
'web' => [
// Other middleware...
\App\Http\Middleware\SetRbacExternalId::class,
],
];
Migration
Set up RBAC and tables:
// database/migrations/2025_04_12_000001_setup_rbac_subjects.php
use Illuminate\Database\Migrations\Migration;
use Illuminate\Support\Facades\DB;
class SetupRbacSubjects extends Migration
{
public function up()
{
$users = DB::table('users')->get();
foreach ($users as $user) {
DB::statement("SELECT public.c77_rbac_laravel_assign_user(?, ?, ?, ?)", [
$user->id, 'sales_manager', 'campus', 'chicago'
]);
}
DB::statement("SELECT public.c77_rbac_grant_feature(?, ?)", [
'sales_manager', 'view_sales_page'
]);
}
public function down()
{
DB::statement("TRUNCATE public.c77_rbac_subjects CASCADE");
DB::statement("TRUNCATE public.c77_rbac_roles CASCADE");
DB::statement("TRUNCATE public.c77_rbac_features CASCADE");
}
}
use Illuminate\Database\Migrations\Migration;
use Illuminate\Database\Schema\Blueprint;
use Illuminate\Support\Facades\DB;
use Illuminate\Support\Facades\Schema;
class CreateSalesTable extends Migration
{
public function up()
{
Schema::create('sales', function (Blueprint $table) {
$table->id();
$table->string('campus');
$table->decimal('amount');
});
DB::statement("ALTER TABLE public.sales ENABLE ROW LEVEL SECURITY");
DB::statement("
CREATE POLICY rbac_policy ON public.sales
FOR ALL TO PUBLIC
USING (public.c77_rbac_can_access('view_sales_page', public.c77_rbac_laravel_auth_id(), 'campus', campus))
");
}
public function down()
{
DB::statement("DROP TABLE public.sales CASCADE");
}
}
Run:
php artisan migrate
Querying
use Illuminate\Support\Facades\DB;
public function index()
{
$sales = DB::table('sales')->get();
return view('sales.index', ['sales' => $sales]);
}
Logged-in users see only authorized rows (e.g., chicago
for user ID 1
).
Notes
- Security:
c77_rbac_*
tables are protected; onlySECURITY DEFINER
functions access them. The application user (app_user
) needsEXECUTE
on functions andSELECT/INSERT/UPDATE/DELETE
on application tables (e.g.,sales
). - Materialized Views: PostgreSQL materialized views don’t support RLS. Use regular views for dynamic filtering:
CREATE VIEW public.sales_view AS SELECT * FROM public.sales;
- Future Enhancements: Planned features include dynamic policy management and support for other frameworks (Django, Rails).
Testing
Verify the extension:
CREATE DATABASE c77_rbac_test;
\c c77_rbac_test
CREATE EXTENSION c77_rbac;
CREATE EXTENSION c77_rbac_laravel;
SELECT public.c77_rbac_laravel_assign_user(1, 'sales_manager', 'campus', 'chicago');
SELECT public.c77_rbac_grant_feature('sales_manager', 'view_sales_page');
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);
ALTER TABLE public.sales ENABLE ROW LEVEL SECURITY;
CREATE POLICY rbac_policy ON public.sales FOR ALL TO PUBLIC USING (
public.c77_rbac_can_access('view_sales_page', public.c77_rbac_laravel_auth_id(), 'campus', campus)
);
SET "c77_rbac.external_id" TO '1';
SELECT * FROM public.sales;
License
MIT License. See LICENSE
for details.
Contributing
Issues and pull requests are welcome on GitHub (replace with your repo if applicable).
Authors
- Your Name (or leave blank for now)
Generated with help from Grok 3, built by xAI.