12 KiB
c77_rbac Usage Guide
This guide provides detailed instructions on using the c77_rbac
PostgreSQL extension for Role-Based Access Control (RBAC) with Row-Level Security (RLS). The c77_rbac
extension is an agnostic RBAC system that works with any application. This document assumes the extension is installed (see README.md
for setup) and focuses on practical usage, examples, and best practices.
Table of Contents
Overview
c77_rbac
enables database-driven authorization in PostgreSQL, using RBAC to manage roles and permissions, and RLS to restrict row access. Key features:
- Agnostic Design: Uses
external_id
(TEXT) to identify subjects, compatible with any framework. - Scoped Permissions: Roles can be tied to scopes (e.g.,
campus/chicago
) for granular control. - Secure Execution:
SECURITY DEFINER
functions protect RBAC metadata, requiring no direct table access.
This guide uses app_user
as the database user for all operations, assuming a single-user setup typical for applications.
Core Concepts
- Subject: An entity (user, system) identified by
external_id
(e.g.,'1'
for a user ID). - Role: A named group of permissions (e.g.,
sales_manager
). - Feature: A specific permission (e.g.,
view_sales_page
). - Scope: A context for permissions, defined by
scope_type
andscope_id
(e.g.,campus/chicago
). - RLS Policy: A PostgreSQL policy that uses
c77_rbac_can_access
to filter rows based on RBAC rules. - Admin Role: A special role (
admin
) that bypasses scope restrictions for universal access.
Tables:
c77_rbac_subjects
: Stores subjects (external_id
,scope_type
,scope_id
).c77_rbac_roles
: Stores roles (name
).c77_rbac_features
: Stores features (name
).c77_rbac_subject_roles
: Links subjects to roles with scopes.c77_rbac_role_features
: Links roles to features.
Using c77_rbac
Assigning Subjects
Use c77_rbac_assign_subject
to assign a role to a subject with an optional scope:
SELECT public.c77_rbac_assign_subject('1', 'sales_manager', 'campus', 'chicago');
- Parameters:
p_external_id
: Unique identifier (e.g.,'1'
).p_role_name
: Role to assign (e.g.,sales_manager
).p_scope_type
: Scope category (e.g.,campus
). Can beNULL
.p_scope_id
: Scope value (e.g.,chicago
). Can beNULL
.
- Effect: Creates/updates a subject in
c77_rbac_subjects
, ensures the role exists inc77_rbac_roles
, and links them inc77_rbac_subject_roles
.
Example: Assign a subject without scope:
SELECT public.c77_rbac_assign_subject('2', 'viewer', NULL, NULL);
Granting Features
Use c77_rbac_grant_feature
to grant a feature to a role:
SELECT public.c77_rbac_grant_feature('sales_manager', 'view_sales_page');
- Parameters:
p_role_name
: Role to grant to.p_feature_name
: Feature to grant.
- Effect: Ensures the role and feature exist, then links them in
c77_rbac_role_features
.
Example: Grant multiple features:
SELECT public.c77_rbac_grant_feature('sales_manager', 'edit_sales_page');
SELECT public.c77_rbac_grant_feature('sales_manager', 'delete_sales_page');
Checking Access
Use c77_rbac_can_access
to verify if a subject has access to a feature within a scope:
SELECT public.c77_rbac_can_access('view_sales_page', '1', 'campus', 'chicago');
- Parameters:
p_feature_name
: Feature to check.p_external_id
: Subject's identifier.p_scope_type
: Scope category (optional).p_scope_id
: Scope value (optional).
- Returns:
TRUE
if access is granted,FALSE
otherwise. - Note: Raises an error if
p_external_id
isNULL
.
Example: Check multiple scopes:
SELECT 'chicago' AS campus, public.c77_rbac_can_access('view_sales_page', '1', 'campus', 'chicago') AS can_access
UNION ALL
SELECT 'miami' AS campus, public.c77_rbac_can_access('view_sales_page', '1', 'campus', 'miami') AS can_access;
Expected Output (based on prior setup):
campus | can_access
---------+------------
chicago | t
miami | f
(2 rows)
Applying RLS Policies
Create RLS policies on tables to enforce RBAC rules. Example with a sales
table:
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)
);
- Effect: Only rows where
c77_rbac_can_access
returnsTRUE
are accessible. - Note: Uses the session variable
c77_rbac.external_id
set by the application.
Test:
SET "c77_rbac.external_id" TO '1';
SELECT * FROM public.sales;
Expected Output:
id | campus | amount
----+---------+--------
1 | chicago | 1000
(1 row)
Without external_id
:
RESET "c77_rbac.external_id";
SELECT * FROM public.sales;
Expected Output:
id | campus | amount
----+--------+--------
(0 rows)
Admin Role
The admin
role bypasses scope restrictions for features it's granted:
SELECT public.c77_rbac_assign_subject('999', 'admin', NULL, NULL);
SELECT public.c77_rbac_grant_feature('admin', 'view_sales_page');
SET "c77_rbac.external_id" TO '999';
SELECT * FROM public.sales;
Expected Output:
id | campus | amount
----+---------+--------
1 | chicago | 1000
2 | miami | 2000
(2 rows)
- Use Case: Assign
admin
to superusers who need full access. - Note:
admin
only bypasses scope checks, not feature checks (must still haveview_sales_page
).
Best Practices
- Single User: Use one PostgreSQL user (e.g.,
app_user
) for migrations and runtime to avoid permission issues. - Secure Functions: All
c77_rbac
functions areSECURITY DEFINER
, so don't grant directSELECT
onc77_rbac_*
tables. - Scoped Roles: Always define scopes (
scope_type
,scope_id
) for non-admin roles to enforce granular access. - Admin Sparingly: Reserve the
admin
role for superusers, and audit its assignments. - RLS on All Tables: Apply RLS policies to any table with sensitive data, using
c77_rbac_can_access
. - Test Policies: Verify RLS behavior with different
external_id
values before deploying. - Session Management: Ensure your application correctly sets
c77_rbac.external_id
for each database session.
Edge Cases
- No
external_id
Set:- Queries return no rows (RLS policy fails).
- Fix: Ensure your application sets the session variable with
SET "c77_rbac.external_id" TO 'your_user_id';
.
- Invalid
external_id
:- If
external_id
doesn't exist inc77_rbac_subjects
,c77_rbac_can_access
returnsFALSE
. - Fix: Ensure subjects are assigned roles.
- If
- Missing Role/Feature:
c77_rbac_can_access
returnsFALSE
if the role or feature isn't assigned.- Fix: Use
c77_rbac_assign_subject
andc77_rbac_grant_feature
to set up.
- Scope Mismatch:
- Access denied if
scope_type
/scope_id
don't match exactly. - Example: User with
campus/chicago
can't accesscampus/miami
.
- Access denied if
- Admin Overreach:
admin
bypasses scope but needs explicit feature grants.- Example:
admin
withoutview_sales_page
getsFALSE
.
- Database Connection Pooling:
- If using connection pooling, ensure
c77_rbac.external_id
is reset or set for each request. - Consider using a connection interceptor to set
external_id
based on the current user.
- If using connection pooling, ensure
Testing and Debugging
To test the setup:
-- Setup
SELECT public.c77_rbac_assign_subject('1', 'sales_manager', 'campus', 'chicago');
SELECT public.c77_rbac_grant_feature('sales_manager', 'view_sales_page');
SELECT public.c77_rbac_assign_subject('999', 'admin', NULL, NULL);
SELECT public.c77_rbac_grant_feature('admin', '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)
);
-- Test regular user
SET "c77_rbac.external_id" TO '1';
SELECT * FROM public.sales;
SELECT 'chicago' AS campus, public.c77_rbac_can_access('view_sales_page', '1', 'campus', 'chicago') AS can_access
UNION ALL
SELECT 'miami' AS campus, public.c77_rbac_can_access('view_sales_page', '1', 'campus', 'miami') AS can_access;
-- Test admin
SET "c77_rbac.external_id" TO '999';
SELECT * FROM public.sales;
Expected Output:
id | campus | amount
----+---------+--------
1 | chicago | 1000
(1 row)
campus | can_access
---------+------------
chicago | t
miami | f
(2 rows)
id | campus | amount
----+---------+--------
1 | chicago | 1000
2 | miami | 2000
(2 rows)
Debug tips:
- No Rows Returned: Check if
external_id
is set (SELECT current_setting('c77_rbac.external_id', true);
). - Access Denied: Verify subject, role, and feature assignments in
c77_rbac_*
tables (requires superuser). - RLS Issues: Test
c77_rbac_can_access
directly with known inputs (as above). - Transaction Isolation: Be aware that changes to RBAC assignments need to be visible in the current transaction.
Limitations
- Materialized Views: PostgreSQL materialized views don't support RLS. Use regular views:
CREATE VIEW public.sales_view AS SELECT * FROM public.sales;
- Dynamic Policies: Policies are hardcoded in migrations. Future versions may add dynamic policy management.
- Single
external_id
: Only oneexternal_id
per session. Multi-user contexts require separate connections. - Performance: Complex scopes may impact query performance. Index
c77_rbac_*
tables if needed. - Session Variables: Relies on session variables, which require careful management in connection pooling scenarios.
Application Integration Examples
Setting External ID
Most applications will need to set the external ID session variable for each database connection:
-- Set the external ID to the current user's ID
SET "c77_rbac.external_id" TO '1';
For web applications, this is typically done at the start of each request.
Transaction Handling
When using transactions, ensure RBAC changes are committed before checking access:
BEGIN;
SELECT public.c77_rbac_assign_subject('2', 'reporter', 'department', 'finance');
SELECT public.c77_rbac_grant_feature('reporter', 'view_reports');
COMMIT;
-- Now in a new transaction
BEGIN;
SET "c77_rbac.external_id" TO '2';
SELECT * FROM reports; -- Will use the new permissions
Multi-tenant Systems
For multi-tenant systems, you can use scopes to separate data by tenant:
-- Assign users to tenant-specific roles
SELECT public.c77_rbac_assign_subject('101', 'tenant_user', 'tenant', 'acme_corp');
SELECT public.c77_rbac_assign_subject('102', 'tenant_user', 'tenant', 'globex');
-- Grant features to the role
SELECT public.c77_rbac_grant_feature('tenant_user', 'view_data');
-- Create RLS policy using tenant scope
CREATE POLICY tenant_isolation ON customer_data FOR ALL TO PUBLIC USING (
public.c77_rbac_can_access('view_data', current_setting('c77_rbac.external_id', true), 'tenant', tenant_id)
);
This ensures users from one tenant cannot see data from another tenant.