diff --git a/README.md b/README.md index 9c40ae6..00adbc2 100644 --- a/README.md +++ b/README.md @@ -1,202 +1,29 @@ -# c77_rbac +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). +Features -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. +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. -## Features +Installation -- **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. +Ensure PostgreSQL 14 or later is installed. -## Requirements +Place c77_rbac.control and c77_rbac--1.1.0.sql in /usr/share/postgresql/17/extension/. -- 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. +Run as a superuser: +CREATE EXTENSION c77_rbac SCHEMA public; -## Installation -### Step 1: Install Extension -Copy the extension files to your PostgreSQL extension directory: +Usage +See USAGE.md for beginner-friendly instructions on securing tables and assigning roles. +Requirements -```bash -sudo cp c77_rbac--1.0.sql c77_rbac.control /usr/share/postgresql/17/extension/ -``` +PostgreSQL 14 or later. +Superuser access for installation. -### Step 2: Create a Database - -```sql --- 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`: - -```sql -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 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. - -## Usage - -### Example: Basic Setup - -```sql --- 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 - -```sql --- 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: - -1. **Set External ID**: Set the session variable before queries: - ```sql - SET "c77_rbac.external_id" TO 'your_user_id'; - ``` - -2. **Apply RLS Policies**: Create policies on tables that check permissions: - ```sql - 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) - ); - ``` - -3. **Initialize RBAC**: During database setup, create your roles and assign features: - ```sql - 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; only `SECURITY DEFINER` functions access them. The application user (`app_user`) needs `EXECUTE` on functions and `SELECT/INSERT/UPDATE/DELETE` on application tables. -- **Materialized Views**: PostgreSQL materialized views don't support RLS. Use regular views for dynamic filtering: - ```sql - 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: - -```sql -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) -- \ No newline at end of file +License +MIT License diff --git a/USAGE.md b/USAGE.md index 5537a23..c0ff08e 100644 --- a/USAGE.md +++ b/USAGE.md @@ -1,337 +1,150 @@ -# c77_rbac Usage Guide +c77_rbac 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). +What is c77_rbac? +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. +Prerequisites -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. +PostgreSQL 14 or later. +A superuser (e.g., homestead) for installation. +A database (e.g., c77_rbac_test). +Basic SQL knowledge. -## Table of Contents +Step 1: Install the Extension -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. [Best Practices](#best-practices) -5. [Edge Cases](#edge-cases) -6. [Testing and Debugging](#testing-and-debugging) -7. [Limitations](#limitations) +Log in as the superuser: +psql -h 192.168.49.115 -p 5432 -U homestead -d c77_rbac_test -## 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. +Create the extension: +CREATE EXTENSION c77_rbac SCHEMA public; -This guide uses `app_user` as the database user for all operations, assuming a single-user setup typical for applications. +This sets up c77_rbac_ tables and functions in public. -## Core Concepts +Exit: +\q -- **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` +Step 2: Set Up Your Application Schema +Use a custom schema (e.g., myapp) for your tables. -### Assigning Subjects +Log in as your application user (e.g., app_user): +psql -h 192.168.49.115 -p 5432 -U app_user -d c77_rbac_test -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'); -``` +Create the myapp schema: +CREATE SCHEMA myapp; -- **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`: 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` 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 +Create a test table: +CREATE TABLE myapp.orders ( +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` returns `TRUE` are accessible. -- **Note**: 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; -``` +Insert test data: +INSERT INTO myapp.orders (campus, amount) VALUES ('chicago', 500), ('miami', 1500); -**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) -``` +Step 3: Apply Row-Level Security (RLS) -### Admin Role +Apply an RLS policy: +SELECT public.c77_rbac_apply_policy('myapp.orders', 'view_sales_page', 'campus', 'campus'); -The `admin` role bypasses scope restrictions for features it's 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; -``` +myapp.orders: Table to secure. +view_sales_page: Required permission. +campus: Scope type. +campus: Column for scope (e.g., chicago). -**Expected Output**: -``` - id | campus | amount -----+---------+-------- - 1 | chicago | 1000 - 2 | miami | 2000 -(2 rows) -``` +A NOTICE: policy "c77_rbac_policy" ... does not exist is normal for new tables. -- **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`). +Check the policy: +\dp myapp.orders -## Best Practices +Expect c77_rbac_policy with: +c77_rbac_can_access('view_sales_page'::text, current_setting('c77_rbac.external_id'::text, true), 'campus'::text, campus) -- **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 don't 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. -- **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 in `c77_rbac_subjects`, `c77_rbac_can_access` returns `FALSE`. - - Fix: Ensure subjects are assigned roles. -- **Missing Role/Feature**: - - `c77_rbac_can_access` returns `FALSE` if the role or feature isn't assigned. - - Fix: Use `c77_rbac_assign_subject` and `c77_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 access `campus/miami`. -- **Admin Overreach**: - - `admin` bypasses scope but needs explicit feature grants. - - Example: `admin` without `view_sales_page` gets `FALSE`. -- **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. +Step 4: Assign Roles to Users +Users have an external_id (e.g., '1', '2'). Admin rights use global/all. -## Testing and Debugging - -To test the setup: - -```sql --- Setup +Assign a sales manager role (Chicago): 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); + + +Assign an admin role (all data): +SELECT public.c77_rbac_assign_subject('999', 'admin', 'global', 'all'); 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) -); +For another admin (e.g., '2'): +SELECT public.c77_rbac_assign_subject('2', 'admin', 'global', 'all'); +SELECT public.c77_rbac_grant_feature('admin', 'view_sales_page'); --- Test regular user + + +Step 5: Test Access + +Chicago manager: 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; +SELECT * FROM myapp.orders; --- Test admin -SET "c77_rbac.external_id" TO '999'; -SELECT * FROM public.sales; -``` - -**Expected Output**: -``` - id | campus | amount +Expected: +id | campus | amount ----+---------+-------- - 1 | chicago | 1000 -(1 row) +1 | chicago | 500 - 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: - ```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. -- **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: - -```sql --- 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: - -```sql -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; +Admin (e.g., '2'): SET "c77_rbac.external_id" TO '2'; -SELECT * FROM reports; -- Will use the new permissions -``` +SELECT * FROM myapp.orders; -### Multi-tenant Systems +Expected: +id | campus | amount +----+---------+-------- +1 | chicago | 500 +2 | miami | 1500 -For multi-tenant systems, you can use scopes to separate data by tenant: -```sql --- 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'); +Unauthorized user: +SET "c77_rbac.external_id" TO 'unknown'; +SELECT * FROM myapp.orders; --- Grant features to the role -SELECT public.c77_rbac_grant_feature('tenant_user', 'view_data'); +Expected: +id | campus | amount +----+--------+-------- --- 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. \ No newline at end of file + +Step 6: Use in Your Application +For Laravel: + +Set user ID: +DB::statement("SET c77_rbac.external_id TO '1'"); + + +Query: +SELECT * FROM myapp.orders; + + + +Troubleshooting + +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. + +Notes + +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. + +For help, ask your database administrator or the c77_rbac community. diff --git a/c77_rbac--1.1.0.sql b/c77_rbac--1.1.0.sql new file mode 100644 index 0000000..aebc524 --- /dev/null +++ b/c77_rbac--1.1.0.sql @@ -0,0 +1,204 @@ +-- c77_rbac--1.1.0.sql: PostgreSQL extension for role-based access control (RBAC) +-- Requires PostgreSQL 14 or later +-- All objects in public schema with c77_rbac_ prefix +\echo Use "CREATE EXTENSION c77_rbac" to load this file. \quit + +-- Tables +CREATE TABLE public.c77_rbac_subjects ( + subject_id BIGSERIAL PRIMARY KEY, + external_id TEXT UNIQUE NOT NULL +); + +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 NOT NULL, + 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) +); + +-- Function: c77_rbac_assign_subject +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) + VALUES (p_external_id) + ON CONFLICT (external_id) DO NOTHING + RETURNING subject_id INTO v_subject_id; + + IF v_subject_id IS NULL THEN + SELECT subject_id INTO v_subject_id + FROM public.c77_rbac_subjects + WHERE external_id = p_external_id; + END IF; + + 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; + +-- Function: c77_rbac_grant_feature +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; + +-- Function: c77_rbac_can_access +CREATE OR REPLACE FUNCTION public.c77_rbac_can_access( + p_feature_name TEXT, + p_external_id TEXT, + p_scope_type TEXT, + p_scope_id TEXT +) RETURNS BOOLEAN AS $$ +BEGIN + IF p_external_id IS NULL THEN + RAISE EXCEPTION 'p_external_id must be provided'; + END IF; + + -- Admin bypass (global/all scope) + 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.id + WHERE s.external_id = p_external_id + AND f.name = p_feature_name + AND sr.scope_type = 'global' + AND sr.scope_id = 'all' + ) THEN + RETURN TRUE; + END IF; + + -- Regular access check + RETURN 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.id + WHERE s.external_id = p_external_id + AND f.name = p_feature_name + AND sr.scope_type = p_scope_type + AND sr.scope_id = p_scope_id + ); +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; + +-- Function: c77_rbac_apply_policy +CREATE OR REPLACE FUNCTION public.c77_rbac_apply_policy( + p_table_name TEXT, + p_feature_name TEXT, + p_scope_type TEXT, + p_scope_column TEXT +) RETURNS VOID AS $$ +DECLARE + v_schema_name TEXT; + v_table_name TEXT; +BEGIN + -- Split schema and table name + IF p_table_name LIKE '%.%' THEN + v_schema_name := split_part(p_table_name, '.', 1); + v_table_name := split_part(p_table_name, '.', 2); + ELSE + v_schema_name := 'public'; + v_table_name := p_table_name; + END IF; + + -- Drop existing policy + EXECUTE format('DROP POLICY IF EXISTS c77_rbac_policy ON %I.%I', v_schema_name, v_table_name); + + -- Create policy with fully qualified column + EXECUTE format( + 'CREATE POLICY c77_rbac_policy ON %I.%I FOR ALL TO PUBLIC USING ( + public.c77_rbac_can_access(%L, current_setting(''c77_rbac.external_id'', true), %L, %I.%I.%I) + )', + v_schema_name, v_table_name, p_feature_name, p_scope_type, v_schema_name, v_table_name, p_scope_column + ); + + -- Enable and force RLS + EXECUTE format('ALTER TABLE %I.%I ENABLE ROW LEVEL SECURITY', v_schema_name, v_table_name); + EXECUTE format('ALTER TABLE %I.%I FORCE ROW LEVEL SECURITY', v_schema_name, v_table_name); +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; + +-- Grant permissions +GRANT USAGE ON SCHEMA public TO PUBLIC; +GRANT SELECT, INSERT, UPDATE, DELETE ON public.c77_rbac_subjects, public.c77_rbac_roles, public.c77_rbac_features, + public.c77_rbac_subject_roles, public.c77_rbac_role_features TO PUBLIC; +GRANT EXECUTE ON FUNCTION public.c77_rbac_assign_subject(TEXT, TEXT, TEXT, TEXT), + public.c77_rbac_grant_feature(TEXT, TEXT), + public.c77_rbac_can_access(TEXT, TEXT, TEXT, TEXT), + public.c77_rbac_apply_policy(TEXT, TEXT, TEXT, TEXT) TO PUBLIC; + +-- Set default privileges for future objects +ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT SELECT, INSERT, UPDATE, DELETE ON TABLES TO PUBLIC; +ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT EXECUTE ON FUNCTIONS TO PUBLIC; \ No newline at end of file diff --git a/c77_rbac.control b/c77_rbac.control index 6a173f5..9bfde1d 100644 --- a/c77_rbac.control +++ b/c77_rbac.control @@ -1,5 +1,5 @@ # /usr/share/postgresql/17/extension/c77_rbac.control comment = 'Agnostic RBAC system for PostgreSQL' -default_version = '1.0.0' +default_version = '1.1.0' module_pathname = '$libdir/c77_rbac' relocatable = true