Release 1.0.0 c77_rbac

This commit is contained in:
trogers1884 2025-04-13 06:38:30 -05:00
parent 4a1a37002a
commit 74ae17dfbd
6 changed files with 786 additions and 370 deletions

1
.idea/sqldialects.xml generated
View File

@ -1,7 +1,6 @@
<?xml version="1.0" encoding="UTF-8"?> <?xml version="1.0" encoding="UTF-8"?>
<project version="4"> <project version="4">
<component name="SqlDialectMappings"> <component name="SqlDialectMappings">
<file url="file://$PROJECT_DIR$/schema.sql" dialect="PostgreSQL" />
<file url="PROJECT" dialect="PostgreSQL" /> <file url="PROJECT" dialect="PostgreSQL" />
</component> </component>
</project> </project>

447
README.md
View File

@ -1,225 +1,308 @@
# c77_rbac: Role-Based Access Control for PostgreSQL # c77_rbac
`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. 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.
## 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 ## Features
- **Role Assignment**: Assign roles to users with specific scopes (e.g., `sales_manager` for `campus/chicago`). - **Agnostic RBAC Core**: Manage roles, features, and subjects with flexible `external_id` (TEXT) for compatibility with any system (Laravel, Django, Rails, etc.).
- **Feature Grants**: Grant features (permissions) to roles (e.g., `view_sales_page` to `sales_manager`). - **Row-Level Security (RLS)**: Enforce access control directly in PostgreSQL using RLS policies tied to RBAC rules.
- **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')`). - **Scoped Permissions**: Assign roles with scope (e.g., `campus/chicago`) for granular control.
- **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). - **Admin Role Support**: Optional `admin` role bypasses scope restrictions for universal access.
- **Cross-Schema Support**: Apply RLS policies to tables in any schema (e.g., `public.sales` or `other_schema.sales`). - **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.
## Current Status ## Requirements
### What Weve Done So Far - PostgreSQL 13 or later (tested on 17).
- **Schema Design**: - Superuser access to install extensions.
- Created tables in the `public` schema with the `c77_rbac_` prefix: - Application user (e.g., `app_user`) with permissions to create tables and execute functions.
- `c77_rbac_users`: Stores users with their default scope (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 (e.g., `jane` as `sales_manager` for `campus/chicago`).
- `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).
- Updated to use `BIGSERIAL` and `BIGINT` for primary keys to align with Laravel conventions.
- 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`.
- `public.c77_rbac_get_current_user()`: Safely fetches the session variable `c77_rbac.current_user` for RLS.
- **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', '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.
- Fixed RLS filtering:
- Initially, RLS wasnt filtering rows because the default role (`homestead`) was a superuser, which bypasses RLS by default.
- Created a non-superuser role (`test_user`) to test RLS, and confirmed that Jane only sees `chicago` rows as expected.
- Documented the need to use a non-superuser role for testing and production.
- **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
- **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**:
- Add integration guides for other frameworks (e.g., Django, Rails).
- Tag v1.0 in the Git repository (`https://git.jctr3.com/c77_rbac`).
## Installation ## Installation
1. **Install the Extension**: ### Step 1: Install Extensions
- Copy `c77_rbac--1.0.sql` and `c77_rbac.control` to your PostgreSQL extension directory (e.g., `/usr/share/postgresql/14/extension/`).
- Run:
```sql
CREATE EXTENSION c77_rbac;
```
2. **Set Up Permissions**: Copy the extension files to your PostgreSQL extension directory (e.g., `/usr/share/postgresql/17/extension/`):
- Ensure your application role (e.g., `app_user`) has access to the schema and tables:
```sql ```bash
GRANT USAGE ON SCHEMA public TO app_user; sudo cp c77_rbac--1.0.sql c77_rbac.control /usr/share/postgresql/17/extension/
GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO app_user; sudo cp c77_rbac_laravel--1.0.sql c77_rbac_laravel.control /usr/share/postgresql/17/extension/
``` ```
- For tables in other schemas:
```sql ### Step 2: Create a Database
GRANT USAGE ON SCHEMA other_schema TO app_user;
GRANT SELECT, INSERT, UPDATE, DELETE ON other_schema.your_table TO app_user; ```sql
``` -- 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`:
```sql
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 unique `external_id` (TEXT), `scope_type`, and `scope_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()`: Retrieves `external_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 ## Usage
### Assigning Roles and Features ### Example: Basic Setup
```sql
-- 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 ```sql
-- 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'); SELECT public.c77_rbac_grant_feature('sales_manager', 'view_sales_page');
SELECT public.c77_rbac_grant_feature('finance_officer', 'approve_payments');
```
### Checking Access -- Create a sales table with RLS
```sql
-- 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
```sql
-- Create a table with a scope column (e.g., campus)
CREATE TABLE public.sales ( CREATE TABLE public.sales (
id SERIAL PRIMARY KEY, id SERIAL PRIMARY KEY,
campus TEXT NOT NULL, campus TEXT NOT NULL,
amount NUMERIC amount NUMERIC
); );
INSERT INTO public.sales (campus, amount) VALUES ('chicago', 1000), ('miami', 2000); INSERT INTO public.sales (campus, amount) VALUES ('chicago', 1000), ('miami', 2000);
GRANT SELECT, INSERT, UPDATE, DELETE ON public.sales TO PUBLIC; 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)
);
-- Apply RLS policy -- Test as user 1
SELECT public.c77_rbac_apply_policy('public', 'sales', 'view_sales_page', 'campus'); SET "c77_rbac.external_id" TO '1';
SELECT * FROM public.sales;
-- Query as a user (using a non-superuser role)
SET SESSION "c77_rbac.current_user" TO 'jane';
SELECT * FROM public.sales; -- Should only show rows where campus = 'chicago'
``` ```
## Testing RLS with a Non-Superuser Role **Expected Output**:
```
id | campus | amount
----+---------+--------
1 | chicago | 1000
(1 row)
```
Since superusers bypass RLS by default in PostgreSQL, you should test RLS policies using a non-superuser role. Heres how to set up a test role: ### Example: Admin Role
```sql ```sql
CREATE ROLE test_user WITH LOGIN PASSWORD 'test_password'; -- Assign admin role to user 999 (no scope restrictions)
GRANT USAGE ON SCHEMA public TO test_user; SELECT public.c77_rbac_laravel_assign_user(999, 'admin', NULL, NULL);
GRANT USAGE ON SCHEMA other_schema TO test_user; SELECT public.c77_rbac_grant_feature('admin', 'view_sales_page');
GRANT SELECT ON ALL TABLES IN SCHEMA public TO test_user;
GRANT SELECT ON ALL TABLES IN SCHEMA other_schema TO test_user; -- Test as admin
ALTER ROLE test_user WITH NOSUPERUSER; -- Ensure the role is not a superuser SET "c77_rbac.external_id" TO '999';
SELECT * FROM public.sales;
``` ```
Connect as `test_user` and run your queries: **Expected Output**:
```
```sql id | campus | amount
SET SESSION "c77_rbac.current_user" TO 'jane'; ----+---------+--------
SELECT * FROM public.sales; -- Should only show chicago rows 1 | chicago | 1000
SELECT * FROM other_schema.sales; -- Should only show chicago rows 2 | miami | 2000
(2 rows)
``` ```
## Integration with Laravel ## Laravel Integration
1. **Sync Users**: When ready to use with Laravel, configure your `.env`:
Ensure usernames from Laravels `users` table are inserted into `c77_rbac_users`:
```php
use Illuminate\Support\Facades\DB;
$user = Auth::user(); ```env
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:
```php
DB::statement("SET SESSION \"c77_rbac.current_user\" TO ?", [Auth::user()->username]);
```
3. **Check Access**:
```php
$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
}
```
### Laravel Integration Notes
Ensure your Laravel database connection user (defined in `config/database.php`) is **not** a superuser, as superusers bypass RLS by default. Create a dedicated database user for your application:
```sql
CREATE ROLE app_user WITH LOGIN PASSWORD 'app_password';
GRANT USAGE ON SCHEMA public TO app_user;
GRANT USAGE ON SCHEMA other_schema TO app_user;
GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO app_user;
GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA other_schema TO app_user;
ALTER ROLE app_user WITH NOSUPERUSER; -- Ensure the role is not a superuser
```
Update your `.env` file in Laravel:
```
DB_CONNECTION=pgsql DB_CONNECTION=pgsql
DB_HOST=your_host DB_HOST=localhost
DB_PORT=5432 DB_PORT=5432
DB_DATABASE=c77_rbac_dev DB_DATABASE=myapp
DB_USERNAME=app_user DB_USERNAME=app_user
DB_PASSWORD=app_password DB_PASSWORD=your_password
``` ```
## Contributing ### Middleware
Contributions are welcome! Please submit issues or pull requests to the repository at `https://git.jctr3.com/c77_rbac`. Add middleware to set `external_id`:
```php
// 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`:
```php
protected $middlewareGroups = [
'web' => [
// Other middleware...
\App\Http\Middleware\SetRbacExternalId::class,
],
];
```
### Migration
Set up RBAC and tables:
```php
// 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:
```bash
php artisan migrate
```
### Querying
```php
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; only `SECURITY DEFINER` functions access them. The application user (`app_user`) needs `EXECUTE` on functions and `SELECT/INSERT/UPDATE/DELETE` on application tables (e.g., `sales`).
- **Materialized Views**: PostgreSQL materialized views dont support RLS. Use regular views for dynamic filtering:
```sql
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:
```sql
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 ## License
This project is licensed under the MIT License. See the `LICENSE` file for details (to be added). 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.

372
USAGE.md Normal file
View File

@ -0,0 +1,372 @@
# 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, while `c77_rbac_laravel` provides seamless integration for Laravel. This document assumes the extensions are installed (see `README.md` for setup) and focuses on practical usage, examples, and best practices.
## Table of Contents
1. [Overview](#overview)
2. [Core Concepts](#core-concepts)
3. [Using `c77_rbac`](#using-c77_rbac)
- [Assigning Subjects](#assigning-subjects)
- [Granting Features](#granting-features)
- [Checking Access](#checking-access)
- [Applying RLS Policies](#applying-rls-policies)
- [Admin Role](#admin-role)
4. [Using `c77_rbac_laravel`](#using-c77_rbac_laravel)
- [Assigning Laravel Users](#assigning-laravel-users)
- [Setting External ID](#setting-external-id)
- [Laravel Queries with RLS](#laravel-queries-with-rls)
5. [Best Practices](#best-practices)
6. [Edge Cases](#edge-cases)
7. [Testing and Debugging](#testing-and-debugging)
8. [Limitations](#limitations)
## 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.
- **Laravel Support**: `c77_rbac_laravel` maps Laravel user IDs to RBAC subjects and integrates via middleware.
This guide uses `app_user` as the database user for all operations, assuming a single-user setup typical for applications like Laravel.
## 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` and `scope_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:
```sql
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 be `NULL`.
- `p_scope_id`: Scope value (e.g., `chicago`). Can be `NULL`.
- **Effect**: Creates/updates a subject in `c77_rbac_subjects`, ensures the role exists in `c77_rbac_roles`, and links them in `c77_rbac_subject_roles`.
Example: Assign a subject without scope:
```sql
SELECT public.c77_rbac_assign_subject('2', 'viewer', NULL, NULL);
```
### Granting Features
Use `c77_rbac_grant_feature` to grant a feature to a role:
```sql
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:
```sql
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:
```sql
SELECT public.c77_rbac_can_access('view_sales_page', '1', 'campus', 'chicago');
```
- **Parameters**:
- `p_feature_name`: Feature to check.
- `p_external_id`: Subjects 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` is `NULL`.
Example: Check multiple scopes:
```sql
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:
```sql
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)
);
```
- **Effect**: Only rows where `c77_rbac_can_access` returns `TRUE` are accessible.
- **With `c77_rbac_laravel_auth_id`**: Uses the session variable `c77_rbac.external_id` set by the application.
Test:
```sql
SET "c77_rbac.external_id" TO '1';
SELECT * FROM public.sales;
```
**Expected Output**:
```
id | campus | amount
----+---------+--------
1 | chicago | 1000
(1 row)
```
Without `external_id`:
```sql
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 its granted:
```sql
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 have `view_sales_page`).
## Using `c77_rbac_laravel`
### Assigning Laravel Users
Use `c77_rbac_laravel_assign_user` to assign Laravel user IDs to roles:
```sql
SELECT public.c77_rbac_laravel_assign_user(1, 'sales_manager', 'campus', 'chicago');
```
- **Parameters**:
- `p_laravel_id`: Laravel user ID (cast to TEXT for `external_id`).
- Others same as `c77_rbac_assign_subject`.
- **Effect**: Calls `c77_rbac_assign_subject` internally.
Typically done in a migration:
```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'
]);
}
}
}
```
### Setting External ID
The Laravel middleware sets `c77_rbac.external_id`:
```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);
}
}
```
- **Effect**: Sets `external_id` to the logged-in users ID (e.g., `'1'`).
- **Without Middleware**: Queries return no rows (RLS blocks access if `external_id` is unset).
Manual setting for jobs or scripts:
```php
DB::statement('SET "c77_rbac.external_id" TO ?', [1]);
```
### Laravel Queries with RLS
Once the middleware is active, standard queries respect RLS:
```php
use Illuminate\Support\Facades\DB;
public function index()
{
$sales = DB::table('sales')->get();
return view('sales.index', ['sales' => $sales]);
}
```
- **For User ID `1`**: Returns only `chicago` rows.
- **For User ID `999` (admin)**: Returns all rows.
## 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 are `SECURITY DEFINER`, so dont grant direct `SELECT` on `c77_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.
## Edge Cases
- **No `external_id` Set**:
- Queries return no rows (RLS policy fails).
- Fix: Ensure middleware or manual `SET` is in place.
- **Invalid `external_id`**:
- If `external_id` doesnt exist in `c77_rbac_subjects`, `c77_rbac_can_access` returns `FALSE`.
- Fix: Sync users to `c77_rbac_subjects` in migrations.
- **Missing Role/Feature**:
- `c77_rbac_can_access` returns `FALSE` if the role or feature isnt assigned.
- Fix: Use `c77_rbac_assign_subject` and `c77_rbac_grant_feature` to set up.
- **Scope Mismatch**:
- Access denied if `scope_type`/`scope_id` dont match exactly.
- Example: User with `campus/chicago` cant access `campus/miami`.
- **Admin Overreach**:
- `admin` bypasses scope but needs explicit feature grants.
- Example: `admin` without `view_sales_page` gets `FALSE`.
## Testing and Debugging
To test the setup:
```sql
-- Setup
SELECT public.c77_rbac_laravel_assign_user(1, 'sales_manager', 'campus', 'chicago');
SELECT public.c77_rbac_grant_feature('sales_manager', 'view_sales_page');
SELECT public.c77_rbac_laravel_assign_user(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', public.c77_rbac_laravel_auth_id(), '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).
## Limitations
- **Materialized Views**: PostgreSQL materialized views dont support RLS. Use regular views:
```sql
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 one `external_id` per session. Multi-user contexts require separate connections.
- **Performance**: Complex scopes may impact query performance. Index `c77_rbac_*` tables if needed.
---
Generated with help from Grok 3, built by xAI.

144
c77_rbac--1.0.0.sql Normal file
View File

@ -0,0 +1,144 @@
-- /usr/share/postgresql/17/extension/c77_rbac--1.0.sql
\echo Use "CREATE EXTENSION c77_rbac" to load this file. \quit
CREATE TABLE public.c77_rbac_subjects (
subject_id BIGSERIAL PRIMARY KEY,
external_id TEXT UNIQUE NOT NULL,
scope_type TEXT,
scope_id TEXT
);
CREATE TABLE public.c77_rbac_roles (
role_id BIGSERIAL PRIMARY KEY,
name TEXT UNIQUE NOT NULL
);
CREATE TABLE public.c77_rbac_features (
feature_id BIGSERIAL PRIMARY KEY,
name TEXT UNIQUE NOT NULL
);
CREATE TABLE public.c77_rbac_subject_roles (
subject_id BIGINT REFERENCES public.c77_rbac_subjects(subject_id),
role_id BIGINT REFERENCES public.c77_rbac_roles(role_id),
scope_type TEXT,
scope_id TEXT,
PRIMARY KEY (subject_id, role_id, scope_type, scope_id)
);
CREATE TABLE public.c77_rbac_role_features (
role_id BIGINT REFERENCES public.c77_rbac_roles(role_id),
feature_id BIGINT REFERENCES public.c77_rbac_features(feature_id),
PRIMARY KEY (role_id, feature_id)
);
CREATE OR REPLACE FUNCTION public.c77_rbac_assign_subject(
p_external_id TEXT,
p_role_name TEXT,
p_scope_type TEXT,
p_scope_id TEXT
) RETURNS VOID AS $$
DECLARE
v_subject_id BIGINT;
v_role_id BIGINT;
BEGIN
INSERT INTO public.c77_rbac_subjects (external_id, scope_type, scope_id)
VALUES (p_external_id, p_scope_type, p_scope_id)
ON CONFLICT (external_id) DO UPDATE
SET scope_type = EXCLUDED.scope_type,
scope_id = EXCLUDED.scope_id
RETURNING subject_id INTO v_subject_id;
INSERT INTO public.c77_rbac_roles (name)
VALUES (p_role_name)
ON CONFLICT (name) DO NOTHING
RETURNING role_id INTO v_role_id;
IF v_role_id IS NULL THEN
SELECT role_id INTO v_role_id
FROM public.c77_rbac_roles
WHERE name = p_role_name;
END IF;
INSERT INTO public.c77_rbac_subject_roles (subject_id, role_id, scope_type, scope_id)
VALUES (v_subject_id, v_role_id, p_scope_type, p_scope_id)
ON CONFLICT (subject_id, role_id, scope_type, scope_id) DO NOTHING;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
CREATE OR REPLACE FUNCTION public.c77_rbac_grant_feature(
p_role_name TEXT,
p_feature_name TEXT
) RETURNS VOID AS $$
DECLARE
v_role_id BIGINT;
v_feature_id BIGINT;
BEGIN
INSERT INTO public.c77_rbac_roles (name)
VALUES (p_role_name)
ON CONFLICT (name) DO NOTHING
RETURNING role_id INTO v_role_id;
IF v_role_id IS NULL THEN
SELECT role_id INTO v_role_id
FROM public.c77_rbac_roles
WHERE name = p_role_name;
END IF;
INSERT INTO public.c77_rbac_features (name)
VALUES (p_feature_name)
ON CONFLICT (name) DO NOTHING
RETURNING feature_id INTO v_feature_id;
IF v_feature_id IS NULL THEN
SELECT feature_id INTO v_feature_id
FROM public.c77_rbac_features
WHERE name = p_feature_name;
END IF;
INSERT INTO public.c77_rbac_role_features (role_id, feature_id)
VALUES (v_role_id, v_feature_id)
ON CONFLICT (role_id, feature_id) DO NOTHING;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
CREATE OR REPLACE FUNCTION public.c77_rbac_can_access(
p_feature_name TEXT,
p_external_id TEXT,
p_scope_type TEXT DEFAULT NULL,
p_scope_id TEXT DEFAULT NULL
) RETURNS BOOLEAN AS $$
BEGIN
IF p_external_id IS NULL THEN
RAISE EXCEPTION 'p_external_id must be provided';
END IF;
-- Admin bypass
IF EXISTS (
SELECT 1
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
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 s.external_id = p_external_id
AND r.name = 'admin'
AND f.name = p_feature_name
) THEN
RETURN TRUE;
END IF;
RETURN EXISTS (
SELECT 1
FROM public.c77_rbac_subjects s
JOIN public.c77_rbac_subject_roles sr ON s.subject_id = sr.subject_id
AND (p_scope_type IS NULL OR sr.scope_type = p_scope_type)
AND (p_scope_id IS NULL OR sr.scope_id = p_scope_id)
JOIN public.c77_rbac_roles r ON sr.role_id = r.role_id
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 s.external_id = p_external_id
AND f.name = p_feature_name
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;

5
c77_rbac.control Normal file
View File

@ -0,0 +1,5 @@
# /usr/share/postgresql/17/extension/c77_rbac.control
comment = 'Agnostic RBAC system for PostgreSQL'
default_version = '1.0'
module_pathname = '$libdir/c77_rbac'
relocatable = true

View File

@ -1,187 +0,0 @@
-- Core tables for c77_rbac
CREATE TABLE public.c77_rbac_users (
user_id BIGSERIAL PRIMARY KEY,
username TEXT NOT NULL UNIQUE,
scope_type TEXT,
scope_id TEXT
);
CREATE TABLE public.c77_rbac_roles (
role_id BIGSERIAL PRIMARY KEY,
name TEXT NOT NULL UNIQUE
);
CREATE TABLE public.c77_rbac_user_roles (
user_id BIGINT NOT NULL REFERENCES public.c77_rbac_users(user_id),
role_id BIGINT NOT NULL REFERENCES public.c77_rbac_roles(role_id),
scope_type TEXT,
scope_id TEXT,
PRIMARY KEY (user_id, role_id, scope_type, scope_id)
);
CREATE TABLE public.c77_rbac_features (
feature_id BIGSERIAL PRIMARY KEY,
name TEXT NOT NULL UNIQUE
);
CREATE TABLE public.c77_rbac_role_features (
role_id BIGINT NOT NULL REFERENCES public.c77_rbac_roles(role_id),
feature_id BIGINT NOT NULL REFERENCES public.c77_rbac_features(feature_id),
PRIMARY KEY (role_id, feature_id)
);
CREATE TABLE public.c77_rbac_entities (
entity_id BIGSERIAL PRIMARY KEY,
entity_type TEXT NOT NULL,
entity_name TEXT NOT NULL,
parent_id BIGINT REFERENCES public.c77_rbac_entities(entity_id),
UNIQUE (entity_type, entity_name)
);
CREATE OR REPLACE FUNCTION public.c77_rbac_assign_user(
p_username TEXT,
p_role_name TEXT,
p_scope_type TEXT,
p_scope_id TEXT
) RETURNS VOID AS $$
DECLARE
v_user_id BIGINT;
v_role_id BIGINT;
BEGIN
-- Insert or get user
INSERT INTO public.c77_rbac_users (username, scope_type, scope_id)
VALUES (p_username, p_scope_type, p_scope_id)
ON CONFLICT (username) DO UPDATE
SET scope_type = EXCLUDED.scope_type,
scope_id = EXCLUDED.scope_id
RETURNING user_id INTO v_user_id;
-- Insert or get role
INSERT INTO public.c77_rbac_roles (name)
VALUES (p_role_name)
ON CONFLICT (name) DO NOTHING
RETURNING role_id INTO v_role_id;
-- If role wasn't inserted, get existing role_id
IF v_role_id IS NULL THEN
SELECT role_id INTO v_role_id
FROM public.c77_rbac_roles
WHERE name = p_role_name;
END IF;
-- Assign role to user with scope
INSERT INTO public.c77_rbac_user_roles (user_id, role_id, scope_type, scope_id)
VALUES (v_user_id, v_role_id, p_scope_type, p_scope_id)
ON CONFLICT (user_id, role_id, scope_type, scope_id) DO NOTHING;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION public.c77_rbac_grant_feature(
p_role_name TEXT,
p_feature_name TEXT
) RETURNS VOID AS $$
DECLARE
v_role_id BIGINT;
v_feature_id BIGINT;
BEGIN
-- Insert or get role
INSERT INTO public.c77_rbac_roles (name)
VALUES (p_role_name)
ON CONFLICT (name) DO NOTHING
RETURNING role_id INTO v_role_id;
IF v_role_id IS NULL THEN
SELECT role_id INTO v_role_id
FROM public.c77_rbac_roles
WHERE name = p_role_name;
END IF;
-- Insert or get feature
INSERT INTO public.c77_rbac_features (name)
VALUES (p_feature_name)
ON CONFLICT (name) DO NOTHING
RETURNING feature_id INTO v_feature_id;
IF v_feature_id IS NULL THEN
SELECT feature_id INTO v_feature_id
FROM public.c77_rbac_features
WHERE name = p_feature_name;
END IF;
-- Grant feature to role
INSERT INTO public.c77_rbac_role_features (role_id, feature_id)
VALUES (v_role_id, v_feature_id)
ON CONFLICT (role_id, feature_id) DO NOTHING;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION public.c77_rbac_can_access(
p_username TEXT,
p_feature_name TEXT,
p_scope_type TEXT DEFAULT NULL,
p_scope_id TEXT DEFAULT NULL
) RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1
FROM public.c77_rbac_users u
JOIN public.c77_rbac_user_roles ur ON u.user_id = ur.user_id
JOIN public.c77_rbac_roles r ON ur.role_id = r.role_id
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 u.username = p_username
AND f.name = p_feature_name
AND (p_scope_type IS NULL OR u.scope_type = p_scope_type)
AND (p_scope_id IS NULL OR u.scope_id = p_scope_id)
);
END;
$$ LANGUAGE plpgsql SECURITY INVOKER;
CREATE OR REPLACE FUNCTION public.c77_rbac_get_current_user() RETURNS TEXT AS $$
BEGIN
RETURN current_setting('c77_rbac.current_user', true);
EXCEPTION WHEN OTHERS THEN
RETURN NULL; -- Fallback if not set
END;
$$ LANGUAGE plpgsql STABLE;
CREATE OR REPLACE FUNCTION public.c77_rbac_apply_policy(
p_schema_name TEXT,
p_table_name TEXT,
p_feature_name TEXT,
p_scope_column TEXT DEFAULT 'campus'
) RETURNS VOID AS $$
BEGIN
SET LOCAL search_path TO public;
RAISE NOTICE 'Enabling RLS on %.%', p_schema_name, p_table_name;
EXECUTE format('ALTER TABLE %I.%I ENABLE ROW LEVEL SECURITY', p_schema_name, p_table_name);
RAISE NOTICE 'Dropping existing policy on %.%', p_schema_name, p_table_name;
EXECUTE format('DROP POLICY IF EXISTS rbac_policy ON %I.%I', p_schema_name, p_table_name);
RAISE NOTICE 'Creating policy on %.% with feature %, scope column %', p_schema_name, p_table_name, p_feature_name, p_scope_column;
EXECUTE format(
'CREATE POLICY rbac_policy ON %I.%I FOR ALL TO PUBLIC USING (
c77_rbac.can_access(c77_rbac_get_current_user(), %L, ''campus'', %I)
)',
p_schema_name, p_table_name, p_feature_name, p_scope_column
);
END;
$$ LANGUAGE plpgsql;
-- Permissions for Tables
GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO PUBLIC;
GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO PUBLIC;
-- Grant permissions on functions
GRANT EXECUTE ON FUNCTION public.c77_rbac_assign_user(TEXT, TEXT, TEXT, TEXT) TO PUBLIC;
GRANT EXECUTE ON FUNCTION public.c77_rbac_grant_feature(TEXT, TEXT) TO PUBLIC;
GRANT EXECUTE ON FUNCTION public.c77_rbac_can_access(TEXT, TEXT, TEXT, TEXT) TO PUBLIC;
GRANT EXECUTE ON FUNCTION public.c77_rbac_get_current_user() TO PUBLIC;
GRANT EXECUTE ON FUNCTION public.c77_rbac_apply_policy(TEXT, TEXT, TEXT, TEXT) TO PUBLIC;