Ready to Publish c77_rbac
This commit is contained in:
parent
beb338dc16
commit
71a219f47a
263
README.md
263
README.md
@ -1,35 +1,250 @@
|
|||||||
# c77_rbac PostgreSQL Extension
|
# 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`).
|
A PostgreSQL extension that provides Role-Based Access Control (RBAC) with Row-Level Security (RLS) for enterprise applications. This extension pushes authorization logic to the database layer, ensuring consistent security across all application frameworks and direct database access.
|
||||||
|
|
||||||
## Features
|
## Features
|
||||||
|
|
||||||
- Scoped role assignments (e.g., campus-specific access).
|
- **Database-Centric Authorization**: Authorization rules enforced at the database level
|
||||||
- Admin access via `global/all` scope for any user ID.
|
- **Row-Level Security**: Fine-grained access control on individual rows
|
||||||
- RLS policies via `c77_rbac_apply_policy`.
|
- **Scope-Based Permissions**: Support for department, region, or any custom scope
|
||||||
- Compatible with PostgreSQL 14+ and Laravel.
|
- **Global Admin Support**: Special `global/all` scope for administrative access
|
||||||
|
- **Framework Agnostic**: Works with any application framework (Laravel, Rails, Django, etc.)
|
||||||
## Installation
|
- **Dynamic Schema Support**: Works with any PostgreSQL schema
|
||||||
|
- **Performance Optimized**: Includes indexes and efficient access checks
|
||||||
1. Ensure PostgreSQL 14 or later is installed.
|
|
||||||
|
|
||||||
2. Place `c77_rbac.control` and `c77_rbac--1.1.0.sql.backup` in `/usr/share/postgresql/17/extension/`.
|
|
||||||
|
|
||||||
3. Run as a superuser:
|
|
||||||
|
|
||||||
```sql
|
|
||||||
CREATE EXTENSION c77_rbac SCHEMA public;
|
|
||||||
```
|
|
||||||
|
|
||||||
## Usage
|
|
||||||
|
|
||||||
See `USAGE.md` for beginner-friendly instructions on securing tables and assigning roles.
|
|
||||||
|
|
||||||
## Requirements
|
## Requirements
|
||||||
|
|
||||||
- PostgreSQL 14 or later.
|
- PostgreSQL 14 or later
|
||||||
- Superuser access for installation.
|
- Superuser access for initial installation
|
||||||
|
|
||||||
|
## Installation
|
||||||
|
|
||||||
|
1. **Copy extension files to PostgreSQL directory:**
|
||||||
|
```bash
|
||||||
|
sudo cp c77_rbac.control /usr/share/postgresql/14/extension/
|
||||||
|
sudo cp c77_rbac--1.0.sql /usr/share/postgresql/14/extension/
|
||||||
|
```
|
||||||
|
|
||||||
|
2. **Install the extension (requires superuser):**
|
||||||
|
```sql
|
||||||
|
-- Connect as superuser
|
||||||
|
CREATE DATABASE your_db;
|
||||||
|
CREATE USER app_user WITH PASSWORD 'secure_password';
|
||||||
|
|
||||||
|
-- Install extension
|
||||||
|
\c your_db
|
||||||
|
CREATE EXTENSION c77_rbac;
|
||||||
|
|
||||||
|
-- Grant necessary privileges to application user
|
||||||
|
GRANT CREATE ON DATABASE your_db TO app_user;
|
||||||
|
GRANT SELECT ON ALL TABLES IN SCHEMA public TO app_user;
|
||||||
|
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO app_user;
|
||||||
|
GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO app_user;
|
||||||
|
```
|
||||||
|
|
||||||
|
## Core Concepts
|
||||||
|
|
||||||
|
### 1. Subjects (Users)
|
||||||
|
- Identified by an `external_id` (typically your application's user ID)
|
||||||
|
- Can have multiple roles with different scopes
|
||||||
|
|
||||||
|
### 2. Roles
|
||||||
|
- Named collections of features (permissions)
|
||||||
|
- Can be scoped to specific contexts (department, region, etc.)
|
||||||
|
|
||||||
|
### 3. Features
|
||||||
|
- Specific permissions that can be checked in policies
|
||||||
|
- Examples: `view_reports`, `edit_users`, `delete_records`
|
||||||
|
|
||||||
|
### 4. Scopes
|
||||||
|
- Context for role assignments
|
||||||
|
- Examples: `department/engineering`, `region/north`, `global/all`
|
||||||
|
|
||||||
|
## Basic Usage
|
||||||
|
|
||||||
|
### 1. Define Features and Roles
|
||||||
|
```sql
|
||||||
|
-- Define features (permissions)
|
||||||
|
SELECT public.c77_rbac_grant_feature('manager', 'view_reports');
|
||||||
|
SELECT public.c77_rbac_grant_feature('manager', 'edit_reports');
|
||||||
|
SELECT public.c77_rbac_grant_feature('admin', 'manage_users');
|
||||||
|
|
||||||
|
-- Admin roles should have all specific features
|
||||||
|
SELECT public.c77_rbac_grant_feature('admin', 'view_reports');
|
||||||
|
SELECT public.c77_rbac_grant_feature('admin', 'edit_reports');
|
||||||
|
```
|
||||||
|
|
||||||
|
### 2. Assign Users to Roles
|
||||||
|
```sql
|
||||||
|
-- Assign user to manager role for engineering department
|
||||||
|
SELECT public.c77_rbac_assign_subject('123', 'manager', 'department', 'engineering');
|
||||||
|
|
||||||
|
-- Assign admin with global access
|
||||||
|
SELECT public.c77_rbac_assign_subject('1', 'admin', 'global', 'all');
|
||||||
|
```
|
||||||
|
|
||||||
|
### 3. Apply Row-Level Security
|
||||||
|
```sql
|
||||||
|
-- Apply RLS policy to a table
|
||||||
|
SELECT public.c77_rbac_apply_policy(
|
||||||
|
'myschema.reports', -- table name (can be schema-qualified)
|
||||||
|
'view_reports', -- required feature
|
||||||
|
'department', -- scope type
|
||||||
|
'department_id' -- column containing scope value
|
||||||
|
);
|
||||||
|
```
|
||||||
|
|
||||||
|
### 4. Set User Context
|
||||||
|
```sql
|
||||||
|
-- Set the current user for RLS checks
|
||||||
|
SET "c77_rbac.external_id" TO '123';
|
||||||
|
|
||||||
|
-- Now queries automatically filter based on permissions
|
||||||
|
SELECT * FROM myschema.reports; -- Only shows reports for user's department
|
||||||
|
```
|
||||||
|
|
||||||
|
## Admin Management
|
||||||
|
|
||||||
|
Administrators with `global/all` scope need explicit feature grants. Use helper functions to manage this:
|
||||||
|
|
||||||
|
```sql
|
||||||
|
-- Sync all features to admin role
|
||||||
|
SELECT public.c77_rbac_sync_admin_features();
|
||||||
|
|
||||||
|
-- Or sync to all roles with global/all scope
|
||||||
|
SELECT public.c77_rbac_sync_global_admin_features();
|
||||||
|
```
|
||||||
|
|
||||||
|
## Integration Examples
|
||||||
|
|
||||||
|
### Laravel Integration
|
||||||
|
```php
|
||||||
|
// Middleware to set user context
|
||||||
|
public function handle($request, Closure $next)
|
||||||
|
{
|
||||||
|
if (Auth::check()) {
|
||||||
|
DB::statement('SET "c77_rbac.external_id" TO ?', [Auth::id()]);
|
||||||
|
}
|
||||||
|
return $next($request);
|
||||||
|
}
|
||||||
|
|
||||||
|
// Check permissions
|
||||||
|
$canView = DB::selectOne("
|
||||||
|
SELECT public.c77_rbac_can_access(?, ?, ?, ?) AS allowed
|
||||||
|
", ['view_reports', Auth::id(), 'department', 'engineering'])->allowed;
|
||||||
|
```
|
||||||
|
|
||||||
|
### Schema-Aware Usage
|
||||||
|
```sql
|
||||||
|
-- Works with any schema
|
||||||
|
CREATE SCHEMA finance;
|
||||||
|
CREATE TABLE finance.accounts (...);
|
||||||
|
|
||||||
|
-- Apply RLS with schema qualification
|
||||||
|
SELECT public.c77_rbac_apply_policy(
|
||||||
|
'finance.accounts',
|
||||||
|
'view_finance',
|
||||||
|
'department',
|
||||||
|
'dept_id'
|
||||||
|
);
|
||||||
|
```
|
||||||
|
|
||||||
|
## Available Functions
|
||||||
|
|
||||||
|
### Core Functions
|
||||||
|
- `c77_rbac_assign_subject(external_id, role, scope_type, scope_id)` - Assign role to user
|
||||||
|
- `c77_rbac_grant_feature(role, feature)` - Grant feature to role
|
||||||
|
- `c77_rbac_can_access(feature, external_id, scope_type, scope_id)` - Check access
|
||||||
|
- `c77_rbac_apply_policy(table, feature, scope_type, column)` - Apply RLS policy
|
||||||
|
|
||||||
|
### Admin Helper Functions
|
||||||
|
- `c77_rbac_sync_admin_features()` - Sync all features to admin role
|
||||||
|
- `c77_rbac_sync_global_admin_features()` - Sync features to all global/all roles
|
||||||
|
|
||||||
|
### Maintenance Functions
|
||||||
|
- `c77_rbac_show_dependencies()` - Show all dependencies on the extension
|
||||||
|
- `c77_rbac_remove_all_policies()` - Remove all RLS policies
|
||||||
|
- `c77_rbac_cleanup_for_removal(remove_data)` - Prepare for extension removal
|
||||||
|
|
||||||
|
## Uninstallation
|
||||||
|
|
||||||
|
1. **Check dependencies:**
|
||||||
|
```sql
|
||||||
|
SELECT * FROM public.c77_rbac_show_dependencies();
|
||||||
|
```
|
||||||
|
|
||||||
|
2. **Remove policies and optionally data:**
|
||||||
|
```sql
|
||||||
|
-- Just remove policies
|
||||||
|
SELECT public.c77_rbac_remove_all_policies();
|
||||||
|
|
||||||
|
-- Or remove policies and all RBAC data
|
||||||
|
SELECT public.c77_rbac_cleanup_for_removal(true);
|
||||||
|
```
|
||||||
|
|
||||||
|
3. **Drop the extension:**
|
||||||
|
```sql
|
||||||
|
DROP EXTENSION c77_rbac CASCADE;
|
||||||
|
```
|
||||||
|
|
||||||
|
## Best Practices
|
||||||
|
|
||||||
|
1. **Feature Naming Convention:**
|
||||||
|
- Use prefixes: `view_*`, `edit_*`, `delete_*`, `manage_*`
|
||||||
|
- Be specific: `view_financial_reports` vs `view_reports`
|
||||||
|
|
||||||
|
2. **Admin Setup:**
|
||||||
|
- Always grant specific features to admin roles
|
||||||
|
- Use sync functions after adding new features
|
||||||
|
- Document all features in your application
|
||||||
|
|
||||||
|
3. **Performance:**
|
||||||
|
- The extension includes optimized indexes
|
||||||
|
- Use explain analyze to verify query plans
|
||||||
|
- Consider materialized views for complex permission checks
|
||||||
|
|
||||||
|
4. **Security:**
|
||||||
|
- Always use parameterized queries
|
||||||
|
- Reset session variables in connection pools
|
||||||
|
- Audit role assignments regularly
|
||||||
|
|
||||||
|
## Troubleshooting
|
||||||
|
|
||||||
|
### No Data Returned
|
||||||
|
1. Check if `c77_rbac.external_id` is set correctly
|
||||||
|
2. Verify user has the required role and features
|
||||||
|
3. Ensure RLS is enabled on the table
|
||||||
|
4. Check that policies reference the correct columns
|
||||||
|
|
||||||
|
### Policy Not Working
|
||||||
|
1. Verify column names match between table and policy
|
||||||
|
2. Check feature names match exactly
|
||||||
|
3. Ensure scope types and IDs align
|
||||||
|
|
||||||
|
### Performance Issues
|
||||||
|
1. Verify indexes exist on RBAC tables
|
||||||
|
2. Check query plans with EXPLAIN ANALYZE
|
||||||
|
3. Consider caching permission checks in your application
|
||||||
|
|
||||||
|
## Contributing
|
||||||
|
|
||||||
|
This extension is designed to be framework-agnostic. When contributing:
|
||||||
|
- Keep the core extension simple and focused
|
||||||
|
- Add framework-specific features to companion extensions
|
||||||
|
- Include tests for new functionality
|
||||||
|
- Update documentation for new features
|
||||||
|
|
||||||
## License
|
## License
|
||||||
|
|
||||||
MIT License
|
MIT License - See LICENSE file for details
|
||||||
|
|
||||||
|
## Support
|
||||||
|
|
||||||
|
- Create an issue for bugs or feature requests
|
||||||
|
- Check existing issues before creating new ones
|
||||||
|
- Include PostgreSQL version and reproduction steps for bugs
|
||||||
|
|
||||||
|
---
|
||||||
|
|
||||||
|
For framework-specific extensions, see:
|
||||||
|
- [c77_rbac_laravel](https://github.com/yourusername/c77_rbac_laravel) - Laravel integration
|
@ -255,6 +255,72 @@ GRANT EXECUTE ON FUNCTION
|
|||||||
public.c77_rbac_apply_policy(TEXT, TEXT, TEXT, TEXT)
|
public.c77_rbac_apply_policy(TEXT, TEXT, TEXT, TEXT)
|
||||||
TO PUBLIC;
|
TO PUBLIC;
|
||||||
|
|
||||||
|
-- Function to remove all RLS policies and prepare for extension removal
|
||||||
|
CREATE OR REPLACE FUNCTION public.c77_rbac_remove_all_policies()
|
||||||
|
RETURNS void AS $$
|
||||||
|
DECLARE
|
||||||
|
policy_record RECORD;
|
||||||
|
table_count INTEGER := 0;
|
||||||
|
BEGIN
|
||||||
|
-- Find and remove all c77_rbac policies
|
||||||
|
FOR policy_record IN
|
||||||
|
SELECT schemaname, tablename, policyname
|
||||||
|
FROM pg_policies
|
||||||
|
WHERE policyname = 'c77_rbac_policy'
|
||||||
|
LOOP
|
||||||
|
EXECUTE format('DROP POLICY IF EXISTS %I ON %I.%I',
|
||||||
|
policy_record.policyname,
|
||||||
|
policy_record.schemaname,
|
||||||
|
policy_record.tablename);
|
||||||
|
|
||||||
|
-- Optionally disable RLS on the table
|
||||||
|
EXECUTE format('ALTER TABLE %I.%I DISABLE ROW LEVEL SECURITY',
|
||||||
|
policy_record.schemaname,
|
||||||
|
policy_record.tablename);
|
||||||
|
|
||||||
|
table_count := table_count + 1;
|
||||||
|
RAISE NOTICE 'Removed policy from %.%', policy_record.schemaname, policy_record.tablename;
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
RAISE NOTICE 'Removed policies from % tables', table_count;
|
||||||
|
RAISE NOTICE 'You can now run: DROP EXTENSION c77_rbac CASCADE;';
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||||
|
|
||||||
|
-- More comprehensive cleanup function that also clears data
|
||||||
|
CREATE OR REPLACE FUNCTION public.c77_rbac_cleanup_for_removal(
|
||||||
|
p_remove_data BOOLEAN DEFAULT false
|
||||||
|
)
|
||||||
|
RETURNS void AS $$
|
||||||
|
DECLARE
|
||||||
|
policy_record RECORD;
|
||||||
|
table_count INTEGER := 0;
|
||||||
|
BEGIN
|
||||||
|
-- First remove all policies
|
||||||
|
PERFORM public.c77_rbac_remove_all_policies();
|
||||||
|
|
||||||
|
-- Optionally clear all RBAC data
|
||||||
|
IF p_remove_data THEN
|
||||||
|
-- Clear in correct order due to foreign keys
|
||||||
|
DELETE FROM public.c77_rbac_subject_roles;
|
||||||
|
DELETE FROM public.c77_rbac_role_features;
|
||||||
|
DELETE FROM public.c77_rbac_subjects;
|
||||||
|
DELETE FROM public.c77_rbac_roles;
|
||||||
|
DELETE FROM public.c77_rbac_features;
|
||||||
|
|
||||||
|
RAISE NOTICE 'Cleared all RBAC data';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
RAISE NOTICE 'Cleanup complete. You can now run: DROP EXTENSION c77_rbac CASCADE;';
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||||
|
|
||||||
|
-- Grant execute permissions
|
||||||
|
GRANT EXECUTE ON FUNCTION
|
||||||
|
public.c77_rbac_remove_all_policies(),
|
||||||
|
public.c77_rbac_cleanup_for_removal(BOOLEAN)
|
||||||
|
TO PUBLIC;
|
||||||
|
|
||||||
-- Grant table permissions with more restrictions
|
-- Grant table permissions with more restrictions
|
||||||
GRANT SELECT ON
|
GRANT SELECT ON
|
||||||
public.c77_rbac_subjects,
|
public.c77_rbac_subjects,
|
||||||
@ -272,3 +338,60 @@ REVOKE INSERT, UPDATE, DELETE ON
|
|||||||
public.c77_rbac_subject_roles,
|
public.c77_rbac_subject_roles,
|
||||||
public.c77_rbac_role_features
|
public.c77_rbac_role_features
|
||||||
FROM PUBLIC;
|
FROM PUBLIC;
|
||||||
|
|
||||||
|
-- Function to show what depends on c77_rbac
|
||||||
|
-- Fixed version of the dependencies function
|
||||||
|
CREATE OR REPLACE FUNCTION public.c77_rbac_show_dependencies()
|
||||||
|
RETURNS TABLE(
|
||||||
|
dependency_type TEXT,
|
||||||
|
schema_name TEXT,
|
||||||
|
object_name TEXT,
|
||||||
|
details TEXT
|
||||||
|
) AS $$
|
||||||
|
BEGIN
|
||||||
|
RETURN QUERY
|
||||||
|
SELECT * FROM (
|
||||||
|
-- Find policies
|
||||||
|
SELECT
|
||||||
|
'POLICY'::TEXT as dependency_type,
|
||||||
|
schemaname::TEXT as schema_name,
|
||||||
|
tablename::TEXT as object_name,
|
||||||
|
policyname::TEXT as details
|
||||||
|
FROM pg_policies
|
||||||
|
WHERE policyname = 'c77_rbac_policy'
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
-- Find tables with RLS enabled
|
||||||
|
SELECT
|
||||||
|
'RLS_ENABLED'::TEXT as dependency_type,
|
||||||
|
schemaname::TEXT as schema_name,
|
||||||
|
tablename::TEXT as object_name,
|
||||||
|
'Row Level Security is enabled'::TEXT as details
|
||||||
|
FROM pg_tables
|
||||||
|
WHERE rowsecurity = true
|
||||||
|
AND (schemaname, tablename) IN (
|
||||||
|
SELECT schemaname, tablename
|
||||||
|
FROM pg_policies
|
||||||
|
WHERE policyname = 'c77_rbac_policy'
|
||||||
|
)
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
-- Find stored procedures that might use c77_rbac functions
|
||||||
|
SELECT DISTINCT
|
||||||
|
'FUNCTION'::TEXT as dependency_type,
|
||||||
|
n.nspname::TEXT as schema_name,
|
||||||
|
p.proname::TEXT as object_name,
|
||||||
|
'May reference c77_rbac functions'::TEXT as details
|
||||||
|
FROM pg_proc p
|
||||||
|
JOIN pg_namespace n ON p.pronamespace = n.oid
|
||||||
|
WHERE p.prosrc LIKE '%c77_rbac%'
|
||||||
|
AND n.nspname NOT IN ('pg_catalog', 'information_schema')
|
||||||
|
AND p.proname NOT LIKE 'c77_rbac%'
|
||||||
|
) AS dependencies
|
||||||
|
ORDER BY dependency_type, schema_name, object_name;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||||
|
|
||||||
|
GRANT EXECUTE ON FUNCTION public.c77_rbac_show_dependencies() TO PUBLIC;
|
||||||
|
Loading…
x
Reference in New Issue
Block a user