c77_rbac
A PostgreSQL extension for Role-Based Access Control (RBAC) with Row-Level Security (RLS) integration. Designed to be framework-agnostic, c77_rbac
works with any application, providing fine-grained, database-driven authorization.
Features
- Agnostic RBAC Core: Manage roles, features, and subjects with flexible
external_id
(TEXT) for compatibility with any system. - 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. - 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 Extension
Copy the extension files to your PostgreSQL extension directory:
sudo cp c77_rbac--1.0.sql c77_rbac.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 Extension
Connect to your database as app_user
:
psql -d myapp -U app_user -h localhost
CREATE EXTENSION c77_rbac;
Database Schema
Core Tables
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.
Usage
Example: Basic Setup
-- As app_user
-- Assign a user (external_id = '1') to sales_manager role for chicago campus
SELECT public.c77_rbac_assign_subject('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 an RLS policy using c77_rbac_can_access
-- Note: You'll need to set c77_rbac.external_id in your application context
CREATE POLICY rbac_policy ON public.sales FOR ALL TO PUBLIC USING (
public.c77_rbac_can_access('view_sales_page', current_setting('c77_rbac.external_id', true), '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_assign_subject('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)
Application Integration
To integrate with your application:
-
Set External ID: Set the session variable before queries:
SET "c77_rbac.external_id" TO 'your_user_id';
-
Apply RLS Policies: Create policies on tables that check permissions:
CREATE POLICY rbac_policy ON your_table FOR ALL TO PUBLIC USING ( public.c77_rbac_can_access('feature_name', current_setting('c77_rbac.external_id', true), 'scope_type', scope_column) );
-
Initialize RBAC: During database setup, create your roles and assign features:
SELECT public.c77_rbac_assign_subject('1', 'editor', 'department', 'marketing'); SELECT public.c77_rbac_grant_feature('editor', 'edit_content');
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. - 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;
- Framework Integration: While designed to be framework-agnostic, you'll need to ensure your application sets the
c77_rbac.external_id
session variable appropriately.
Testing
Verify the extension:
CREATE DATABASE c77_rbac_test;
\c c77_rbac_test
CREATE EXTENSION c77_rbac;
SELECT public.c77_rbac_assign_subject('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', current_setting('c77_rbac.external_id', true), 'campus', campus)
);
SET "c77_rbac.external_id" TO '1';
SELECT * FROM public.sales;
Planned Features
- Revocation functions (
c77_rbac_revoke_feature
,c77_rbac_unassign_subject
) - Functions to list all features available to a subject within a scope
- Role hierarchy support (inheritance)
- Timestamped assignments for auditing
- Framework-specific integration extensions
- Performance optimization for deeply nested scopes
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)
Description
Languages
PLpgSQL
100%