199 lines
4.7 KiB
Markdown
199 lines
4.7 KiB
Markdown
# 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
|
|
|
|
- PostgreSQL 14 or later.
|
|
- A superuser (e.g., `homestead`) for installation.
|
|
- A database (e.g., `c77_rbac_test`).
|
|
- Basic SQL knowledge.
|
|
|
|
## Step 1: Install the Extension
|
|
|
|
1. **Log in as the superuser**:
|
|
|
|
```bash
|
|
psql -h 192.168.49.115 -p 5432 -U homestead -d c77_rbac_test
|
|
```
|
|
|
|
2. **Create the extension**:
|
|
|
|
```sql
|
|
CREATE EXTENSION c77_rbac SCHEMA public;
|
|
```
|
|
|
|
This sets up `c77_rbac_` tables and functions in `public`.
|
|
|
|
3. **Exit**:
|
|
|
|
```sql
|
|
\q
|
|
```
|
|
|
|
## Step 2: Set Up Your Application Schema
|
|
|
|
Use a custom schema (e.g., `myapp`) for your tables.
|
|
|
|
1. **Log in as your application user** (e.g., `app_user`):
|
|
|
|
```bash
|
|
psql -h 192.168.49.115 -p 5432 -U app_user -d c77_rbac_test
|
|
```
|
|
|
|
2. **Create the myapp schema**:
|
|
|
|
```sql
|
|
CREATE SCHEMA myapp;
|
|
```
|
|
|
|
3. **Create a test table**:
|
|
|
|
```sql
|
|
CREATE TABLE myapp.orders (
|
|
id SERIAL PRIMARY KEY,
|
|
campus TEXT NOT NULL,
|
|
amount NUMERIC
|
|
);
|
|
```
|
|
|
|
4. **Insert test data**:
|
|
|
|
```sql
|
|
INSERT INTO myapp.orders (campus, amount) VALUES ('chicago', 500), ('miami', 1500);
|
|
```
|
|
|
|
## Step 3: Apply Row-Level Security (RLS)
|
|
|
|
1. **Apply an RLS policy**:
|
|
|
|
```sql
|
|
SELECT public.c77_rbac_apply_policy('myapp.orders', 'view_sales_page', 'campus', 'campus');
|
|
```
|
|
|
|
- `myapp.orders`: Table to secure.
|
|
- `view_sales_page`: Required permission.
|
|
- `campus`: Scope type.
|
|
- `campus`: Column for scope (e.g., `chicago`).
|
|
|
|
A `NOTICE: policy "c77_rbac_policy" ... does not exist` is normal for new tables.
|
|
|
|
2. **Check the policy**:
|
|
|
|
```sql
|
|
\dp myapp.orders
|
|
```
|
|
|
|
Expect `c77_rbac_policy` with:
|
|
|
|
```
|
|
c77_rbac_can_access('view_sales_page'::text, current_setting('c77_rbac.external_id'::text, true), 'campus'::text, campus)
|
|
```
|
|
|
|
## Step 4: Assign Roles to Users
|
|
|
|
Users have an `external_id` (e.g., `'1'`, `'2'`). Admin rights use `global/all`.
|
|
|
|
1. **Assign a sales manager role** (Chicago):
|
|
|
|
```sql
|
|
SELECT public.c77_rbac_assign_subject('1', 'sales_manager', 'campus', 'chicago');
|
|
SELECT public.c77_rbac_grant_feature('sales_manager', 'view_sales_page');
|
|
```
|
|
|
|
2. **Assign an admin role** (all data):
|
|
|
|
```sql
|
|
SELECT public.c77_rbac_assign_subject('999', 'admin', 'global', 'all');
|
|
SELECT public.c77_rbac_grant_feature('admin', 'view_sales_page');
|
|
```
|
|
|
|
For another admin (e.g., `'2'`):
|
|
|
|
```sql
|
|
SELECT public.c77_rbac_assign_subject('2', 'admin', 'global', 'all');
|
|
SELECT public.c77_rbac_grant_feature('admin', 'view_sales_page');
|
|
```
|
|
|
|
## Step 5: Test Access
|
|
|
|
1. **Chicago manager**:
|
|
|
|
```sql
|
|
SET "c77_rbac.external_id" TO '1';
|
|
SELECT * FROM myapp.orders;
|
|
```
|
|
|
|
**Expected**:
|
|
|
|
```
|
|
id | campus | amount
|
|
----+---------+--------
|
|
1 | chicago | 500
|
|
```
|
|
|
|
2. **Admin** (e.g., `'2'`):
|
|
|
|
```sql
|
|
SET "c77_rbac.external_id" TO '2';
|
|
SELECT * FROM myapp.orders;
|
|
```
|
|
|
|
**Expected**:
|
|
|
|
```
|
|
id | campus | amount
|
|
----+---------+--------
|
|
1 | chicago | 500
|
|
2 | miami | 1500
|
|
```
|
|
|
|
3. **Unauthorized user**:
|
|
|
|
```sql
|
|
SET "c77_rbac.external_id" TO 'unknown';
|
|
SELECT * FROM myapp.orders;
|
|
```
|
|
|
|
**Expected**:
|
|
|
|
```
|
|
id | campus | amount
|
|
----+--------+--------
|
|
```
|
|
|
|
## Step 6: Use in Your Application
|
|
|
|
For Laravel:
|
|
|
|
1. **Set user ID**:
|
|
|
|
```php
|
|
DB::statement("SET c77_rbac.external_id TO '1'");
|
|
```
|
|
|
|
2. **Query**:
|
|
|
|
```sql
|
|
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. |