c77_rbac/README.md

226 lines
11 KiB
Markdown
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

# c77_rbac: Role-Based Access Control for PostgreSQL
`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.
## 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
- **Role Assignment**: Assign roles to users with specific scopes (e.g., `sales_manager` for `campus/chicago`).
- **Feature Grants**: Grant features (permissions) to roles (e.g., `view_sales_page` to `sales_manager`).
- **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')`).
- **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).
- **Cross-Schema Support**: Apply RLS policies to tables in any schema (e.g., `public.sales` or `other_schema.sales`).
## Current Status
### What Weve Done So Far
- **Schema Design**:
- Created tables in the `public` schema with the `c77_rbac_` prefix:
- `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
1. **Install the Extension**:
- 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**:
- Ensure your application role (e.g., `app_user`) has access to the schema and tables:
```sql
GRANT USAGE ON SCHEMA public TO app_user;
GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO app_user;
```
- For tables in other schemas:
```sql
GRANT USAGE ON SCHEMA other_schema TO app_user;
GRANT SELECT, INSERT, UPDATE, DELETE ON other_schema.your_table TO app_user;
```
## Usage
### Assigning Roles and Features
```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
SELECT public.c77_rbac_grant_feature('sales_manager', 'view_sales_page');
SELECT public.c77_rbac_grant_feature('finance_officer', 'approve_payments');
```
### Checking Access
```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 (
id SERIAL PRIMARY KEY,
campus TEXT NOT NULL,
amount NUMERIC
);
INSERT INTO public.sales (campus, amount) VALUES ('chicago', 1000), ('miami', 2000);
GRANT SELECT, INSERT, UPDATE, DELETE ON public.sales TO PUBLIC;
-- Apply RLS policy
SELECT public.c77_rbac_apply_policy('public', 'sales', 'view_sales_page', 'campus');
-- 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
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:
```sql
CREATE ROLE test_user WITH LOGIN PASSWORD 'test_password';
GRANT USAGE ON SCHEMA public TO test_user;
GRANT USAGE ON SCHEMA other_schema TO test_user;
GRANT SELECT ON ALL TABLES IN SCHEMA public TO test_user;
GRANT SELECT ON ALL TABLES IN SCHEMA other_schema TO test_user;
ALTER ROLE test_user WITH NOSUPERUSER; -- Ensure the role is not a superuser
```
Connect as `test_user` and run your queries:
```sql
SET SESSION "c77_rbac.current_user" TO 'jane';
SELECT * FROM public.sales; -- Should only show chicago rows
SELECT * FROM other_schema.sales; -- Should only show chicago rows
```
## Integration with Laravel
1. **Sync Users**:
Ensure usernames from Laravels `users` table are inserted into `c77_rbac_users`:
```php
use Illuminate\Support\Facades\DB;
$user = Auth::user();
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_HOST=your_host
DB_PORT=5432
DB_DATABASE=c77_rbac_dev
DB_USERNAME=app_user
DB_PASSWORD=app_password
```
## Contributing
Contributions are welcome! Please submit issues or pull requests to the repository at `https://git.jctr3.com/c77_rbac`.
## License
This project is licensed under the MIT License. See the `LICENSE` file for details (to be added).