Update sql and readme to current version

This commit is contained in:
trogers1884 2025-04-05 10:36:40 -05:00
parent 356626a2a8
commit 4a1a37002a
2 changed files with 195 additions and 138 deletions

View File

@ -15,7 +15,7 @@ The `c77_rbac` extension aims to:
- **Role Assignment**: Assign roles to users with specific scopes (e.g., `sales_manager` for `campus/chicago`). - **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`). - **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')`). - **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). - **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`). - **Cross-Schema Support**: Apply RLS policies to tables in any schema (e.g., `public.sales` or `other_schema.sales`).
@ -24,12 +24,13 @@ The `c77_rbac` extension aims to:
### What Weve Done So Far ### What Weve Done So Far
- **Schema Design**: - **Schema Design**:
- Created tables in the `public` schema with the `c77_rbac_` prefix: - Created tables in the `public` schema with the `c77_rbac_` prefix:
- `c77_rbac_users`: Stores users with their scopes (e.g., `jane`, `campus`, `chicago`). - `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_roles`: Stores roles (e.g., `sales_manager`, `finance_officer`).
- `c77_rbac_user_roles`: Links users to roles with scopes. - `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_features`: Stores features (e.g., `view_sales_page`, `approve_payments`).
- `c77_rbac_role_features`: Links roles to features. - `c77_rbac_role_features`: Links roles to features.
- `c77_rbac_entities`: Placeholder for future hierarchical entity support (not yet implemented). - `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`. - Committed to `schema.sql`.
- **Core Functions**: - **Core Functions**:
@ -37,6 +38,7 @@ The `c77_rbac` extension aims to:
- `public.c77_rbac_grant_feature(p_role_name TEXT, p_feature_name TEXT)`: Grants a feature to a role. - `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.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_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**: - **Testing**:
- Set up test data: - Set up test data:
@ -44,14 +46,16 @@ The `c77_rbac` extension aims to:
- Features: `view_sales_page` for `sales_manager`, `approve_payments` for `finance_officer`. - Features: `view_sales_page` for `sales_manager`, `approve_payments` for `finance_officer`.
- Tested `public.c77_rbac.can_access`: - 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', 'chicago')``TRUE`.
- `public.c77_rbac.can_access('jane', 'approve_payments', 'campus', 'chicago')``TRUE`.
- `public.c77_rbac.can_access('jane', 'view_sales_page', 'campus', 'miami')``FALSE`. - `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'`). - Created test tables `public.sales` and `other_schema.sales` with sample data (`campus = 'chicago'` and `'miami'`).
- **RLS Implementation**: - **RLS Implementation**:
- Added `public.c77_rbac_apply_policy` to apply RLS policies to tables. - 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. - Used a session variable (`c77_rbac.current_user`) to pass the username to RLS policies.
- Added `public.c77_rbac_get_current_user()` to safely fetch the session variable. - 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**: - **Permissions**:
- Granted `SELECT, INSERT, UPDATE, DELETE` on all `c77_rbac_*` tables to `PUBLIC`. - Granted `SELECT, INSERT, UPDATE, DELETE` on all `c77_rbac_*` tables to `PUBLIC`.
@ -59,26 +63,6 @@ The `c77_rbac` extension aims to:
- Documented the need for `USAGE` on non-`public` schemas (e.g., `GRANT USAGE ON SCHEMA other_schema 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 ### Whats Left to Do
- **Fix RLS Filtering**:
- Currently, RLS policies on `public.sales` and `other_schema.sales` are not filtering rows as expected (Jane sees both `chicago` and `miami` rows, but should only see `chicago`).
- Likely cause: The `homestead` role (or your default role) has the `BYPASSRLS` attribute, which bypasses RLS policies.
- **Next Steps**:
1. Check if `homestead` has `BYPASSRLS`:
```sql
\du homestead
```
2. Remove `BYPASSRLS` if present:
```sql
ALTER ROLE homestead NOBYPASSRLS;
```
3. Retest RLS:
```sql
SET SESSION "c77_rbac.current_user" TO 'jane';
SELECT * FROM public.sales; -- Should show only chicago row
SELECT * FROM other_schema.sales; -- Should show only chicago row
```
4. If still not working, add debugging to `public.c77_rbac_get_current_user()` to log the session variable value.
- **Package as Extension**: - **Package as Extension**:
- Create `c77_rbac--1.0.sql` by copying `schema.sql` and adding the extension header. - Create `c77_rbac--1.0.sql` by copying `schema.sql` and adding the extension header.
- Create `c77_rbac.control` file. - Create `c77_rbac.control` file.
@ -90,7 +74,6 @@ The `c77_rbac` extension aims to:
- Optimize with indexes on frequently queried columns (e.g., `c77_rbac_users.username`, `c77_rbac_user_roles.user_id`). - Optimize with indexes on frequently queried columns (e.g., `c77_rbac_users.username`, `c77_rbac_user_roles.user_id`).
- **Phase 4: Documentation & Packaging**: - **Phase 4: Documentation & Packaging**:
- Expand this `README.md` with detailed usage examples.
- Add integration guides for other frameworks (e.g., Django, Rails). - Add integration guides for other frameworks (e.g., Django, Rails).
- Tag v1.0 in the Git repository (`https://git.jctr3.com/c77_rbac`). - Tag v1.0 in the Git repository (`https://git.jctr3.com/c77_rbac`).
@ -149,11 +132,32 @@ GRANT SELECT, INSERT, UPDATE, DELETE ON public.sales TO PUBLIC;
-- Apply RLS policy -- Apply RLS policy
SELECT public.c77_rbac_apply_policy('public', 'sales', 'view_sales_page', 'campus'); SELECT public.c77_rbac_apply_policy('public', 'sales', 'view_sales_page', 'campus');
-- Query as a user -- Query as a user (using a non-superuser role)
SET SESSION "c77_rbac.current_user" TO 'jane'; SET SESSION "c77_rbac.current_user" TO 'jane';
SELECT * FROM public.sales; -- Should only show rows where campus = 'chicago' 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 ## Integration with Laravel
1. **Sync Users**: 1. **Sync Users**:
@ -188,6 +192,30 @@ SELECT * FROM public.sales; -- Should only show rows where campus = 'chicago'
} }
``` ```
### 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 ## Contributing
Contributions are welcome! Please submit issues or pull requests to the repository at `https://git.jctr3.com/c77_rbac`. Contributions are welcome! Please submit issues or pull requests to the repository at `https://git.jctr3.com/c77_rbac`.
@ -195,4 +223,3 @@ Contributions are welcome! Please submit issues or pull requests to the reposito
## License ## License
This project is licensed under the MIT License. See the `LICENSE` file for details (to be added). This project is licensed under the MIT License. See the `LICENSE` file for details (to be added).

View File

@ -1,101 +1,119 @@
-- Core tables for c77_rbac -- Core tables for c77_rbac
CREATE TABLE c77_rbac_users ( CREATE TABLE public.c77_rbac_users (
user_id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id BIGSERIAL PRIMARY KEY,
username TEXT NOT NULL, 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_type TEXT,
scope_id TEXT, scope_id TEXT,
CONSTRAINT c77_rbac_unique_user_scope UNIQUE (username, scope_type, scope_id) PRIMARY KEY (user_id, role_id, scope_type, scope_id)
); );
CREATE TABLE c77_rbac_roles ( CREATE TABLE public.c77_rbac_features (
role_id UUID PRIMARY KEY DEFAULT gen_random_uuid(), feature_id BIGSERIAL PRIMARY KEY,
name TEXT NOT NULL UNIQUE name TEXT NOT NULL UNIQUE
); );
CREATE TABLE c77_rbac_user_roles ( CREATE TABLE public.c77_rbac_role_features (
user_id UUID REFERENCES c77_rbac_users(user_id), role_id BIGINT NOT NULL REFERENCES public.c77_rbac_roles(role_id),
role_id UUID REFERENCES c77_rbac_roles(role_id), feature_id BIGINT NOT NULL REFERENCES public.c77_rbac_features(feature_id),
PRIMARY KEY (user_id, role_id)
);
CREATE TABLE c77_rbac_features (
feature_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name TEXT NOT NULL UNIQUE
);
CREATE TABLE c77_rbac_role_features (
role_id UUID REFERENCES c77_rbac_roles(role_id),
feature_id UUID REFERENCES c77_rbac_features(feature_id),
PRIMARY KEY (role_id, feature_id) PRIMARY KEY (role_id, feature_id)
); );
-- Optional hierarchy table CREATE TABLE public.c77_rbac_entities (
CREATE TABLE c77_rbac_entities ( entity_id BIGSERIAL PRIMARY KEY,
entity_id UUID PRIMARY KEY DEFAULT gen_random_uuid(), entity_type TEXT NOT NULL,
type TEXT NOT NULL, entity_name TEXT NOT NULL,
name TEXT NOT NULL, parent_id BIGINT REFERENCES public.c77_rbac_entities(entity_id),
parent_id UUID REFERENCES c77_rbac_entities(entity_id), UNIQUE (entity_type, entity_name)
CONSTRAINT c77_rbac_unique_entity UNIQUE (type, name)
); );
CREATE FUNCTION c77_rbac_assign_user( CREATE OR REPLACE FUNCTION public.c77_rbac_assign_user(
p_username TEXT, p_username TEXT,
p_role_name TEXT, p_role_name TEXT,
p_scope_type TEXT, p_scope_type TEXT,
p_scope_id TEXT p_scope_id TEXT
) RETURNS VOID AS $$ ) RETURNS VOID AS $$
DECLARE DECLARE
v_user_id UUID; v_user_id BIGINT;
v_role_id UUID; v_role_id BIGINT;
BEGIN BEGIN
-- Insert or update user with scope -- Insert or get user
INSERT INTO c77_rbac_users (username, scope_type, scope_id) INSERT INTO public.c77_rbac_users (username, scope_type, scope_id)
VALUES (p_username, p_scope_type, p_scope_id) VALUES (p_username, p_scope_type, p_scope_id)
ON CONFLICT ON CONSTRAINT c77_rbac_unique_user_scope ON CONFLICT (username) DO UPDATE
DO UPDATE SET scope_type = EXCLUDED.scope_type, scope_id = EXCLUDED.scope_id SET scope_type = EXCLUDED.scope_type,
scope_id = EXCLUDED.scope_id
RETURNING user_id INTO v_user_id; RETURNING user_id INTO v_user_id;
-- Get or create role -- Insert or get role
SELECT role_id INTO v_role_id FROM c77_rbac_roles WHERE name = p_role_name; INSERT INTO public.c77_rbac_roles (name)
IF v_role_id IS NULL THEN VALUES (p_role_name)
INSERT INTO c77_rbac_roles (name) VALUES (p_role_name) ON CONFLICT (name) DO NOTHING
RETURNING role_id INTO v_role_id; 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; END IF;
-- Link user to role -- Assign role to user with scope
INSERT INTO c77_rbac_user_roles (user_id, role_id) INSERT INTO public.c77_rbac_user_roles (user_id, role_id, scope_type, scope_id)
VALUES (v_user_id, v_role_id) VALUES (v_user_id, v_role_id, p_scope_type, p_scope_id)
ON CONFLICT DO NOTHING; ON CONFLICT (user_id, role_id, scope_type, scope_id) DO NOTHING;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE FUNCTION c77_rbac_grant_feature( CREATE OR REPLACE FUNCTION public.c77_rbac_grant_feature(
p_role_name TEXT, p_role_name TEXT,
p_feature_name TEXT p_feature_name TEXT
) RETURNS VOID AS $$ ) RETURNS VOID AS $$
DECLARE DECLARE
v_role_id UUID; v_role_id BIGINT;
v_feature_id UUID; v_feature_id BIGINT;
BEGIN BEGIN
-- Get or create role -- Insert or get role
SELECT role_id INTO v_role_id FROM c77_rbac_roles WHERE name = p_role_name; INSERT INTO public.c77_rbac_roles (name)
IF v_role_id IS NULL THEN VALUES (p_role_name)
INSERT INTO c77_rbac_roles (name) VALUES (p_role_name) ON CONFLICT (name) DO NOTHING
RETURNING role_id INTO v_role_id; 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; END IF;
-- Get or create feature -- Insert or get feature
INSERT INTO c77_rbac_features (name) INSERT INTO public.c77_rbac_features (name)
VALUES (p_feature_name) VALUES (p_feature_name)
ON CONFLICT (name) DO UPDATE SET name = EXCLUDED.name ON CONFLICT (name) DO NOTHING
RETURNING feature_id INTO v_feature_id; RETURNING feature_id INTO v_feature_id;
-- Link role to feature IF v_feature_id IS NULL THEN
INSERT INTO c77_rbac_role_features (role_id, feature_id) 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) VALUES (v_role_id, v_feature_id)
ON CONFLICT DO NOTHING; ON CONFLICT (role_id, feature_id) DO NOTHING;
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
@ -123,6 +141,15 @@ END;
$$ LANGUAGE plpgsql SECURITY INVOKER; $$ 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( CREATE OR REPLACE FUNCTION public.c77_rbac_apply_policy(
p_schema_name TEXT, p_schema_name TEXT,
p_table_name TEXT, p_table_name TEXT,
@ -130,11 +157,15 @@ CREATE OR REPLACE FUNCTION public.c77_rbac_apply_policy(
p_scope_column TEXT DEFAULT 'campus' p_scope_column TEXT DEFAULT 'campus'
) RETURNS VOID AS $$ ) RETURNS VOID AS $$
BEGIN 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); 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); 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( EXECUTE format(
'CREATE POLICY rbac_policy ON %I.%I FOR ALL TO PUBLIC USING ( 'CREATE POLICY rbac_policy ON %I.%I FOR ALL TO PUBLIC USING (
public.c77_rbac_can_access(current_setting(''c77_rbac.current_user''), %L, ''campus'', %I) c77_rbac.can_access(c77_rbac_get_current_user(), %L, ''campus'', %I)
)', )',
p_schema_name, p_table_name, p_feature_name, p_scope_column p_schema_name, p_table_name, p_feature_name, p_scope_column
); );
@ -142,16 +173,15 @@ END;
$$ LANGUAGE plpgsql; $$ 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 SELECT, INSERT, UPDATE, DELETE ON c77_rbac_users TO PUBLIC;
GRANT SELECT, INSERT, UPDATE, DELETE ON c77_rbac_roles TO PUBLIC;
GRANT SELECT, INSERT, UPDATE, DELETE ON c77_rbac_user_roles TO PUBLIC;
GRANT SELECT, INSERT, UPDATE, DELETE ON c77_rbac_features TO PUBLIC;
GRANT SELECT, INSERT, UPDATE, DELETE ON c77_rbac_role_features TO PUBLIC;
GRANT SELECT, INSERT, UPDATE, DELETE ON c77_rbac_entities TO PUBLIC;
-- Grant permissions on functions -- Grant permissions on functions
GRANT EXECUTE ON FUNCTION c77_rbac_assign_user TO PUBLIC; GRANT EXECUTE ON FUNCTION public.c77_rbac_assign_user(TEXT, TEXT, TEXT, TEXT) TO PUBLIC;
GRANT EXECUTE ON FUNCTION c77_rbac_grant_feature TO PUBLIC; GRANT EXECUTE ON FUNCTION public.c77_rbac_grant_feature(TEXT, TEXT) TO PUBLIC;
GRANT EXECUTE ON FUNCTION c77_rbac_can_access 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;