From beb338dc166500c0757d01a429b2e794918bdc2f Mon Sep 17 00:00:00 2001 From: trogers1884 Date: Sun, 11 May 2025 07:26:05 -0500 Subject: [PATCH] Corrected Code --- README.md | 2 +- ...c--1.0.0.sql => c77_rbac--1.0.0.sql.backup | 0 c77_rbac--1.0.sql | 274 ++++++++++++++++++ ...c--1.1.0.sql => c77_rbac--1.1.0.sql.backup | 0 c77_rbac.control | 11 +- 5 files changed, 281 insertions(+), 6 deletions(-) rename c77_rbac--1.0.0.sql => c77_rbac--1.0.0.sql.backup (100%) create mode 100644 c77_rbac--1.0.sql rename c77_rbac--1.1.0.sql => c77_rbac--1.1.0.sql.backup (100%) diff --git a/README.md b/README.md index 233714f..a085b79 100644 --- a/README.md +++ b/README.md @@ -13,7 +13,7 @@ The `c77_rbac` extension provides role-based access control (RBAC) for PostgreSQ 1. Ensure PostgreSQL 14 or later is installed. -2. Place `c77_rbac.control` and `c77_rbac--1.1.0.sql` in `/usr/share/postgresql/17/extension/`. +2. Place `c77_rbac.control` and `c77_rbac--1.1.0.sql.backup` in `/usr/share/postgresql/17/extension/`. 3. Run as a superuser: diff --git a/c77_rbac--1.0.0.sql b/c77_rbac--1.0.0.sql.backup similarity index 100% rename from c77_rbac--1.0.0.sql rename to c77_rbac--1.0.0.sql.backup diff --git a/c77_rbac--1.0.sql b/c77_rbac--1.0.sql new file mode 100644 index 0000000..373dfba --- /dev/null +++ b/c77_rbac--1.0.sql @@ -0,0 +1,274 @@ +-- c77_rbac--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) ON DELETE CASCADE, + role_id BIGINT REFERENCES public.c77_rbac_roles(role_id) ON DELETE CASCADE, + scope_type TEXT NOT NULL, + scope_id TEXT NOT NULL, + 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) ON DELETE CASCADE, + feature_id BIGINT REFERENCES public.c77_rbac_features(feature_id) ON DELETE CASCADE, + PRIMARY KEY (role_id, feature_id) +); + +-- Create indexes for performance +CREATE INDEX idx_c77_rbac_subjects_external_id ON public.c77_rbac_subjects(external_id); +CREATE INDEX idx_c77_rbac_roles_name ON public.c77_rbac_roles(name); +CREATE INDEX idx_c77_rbac_features_name ON public.c77_rbac_features(name); +CREATE INDEX idx_c77_rbac_subject_roles_subject_id ON public.c77_rbac_subject_roles(subject_id); +CREATE INDEX idx_c77_rbac_subject_roles_role_id ON public.c77_rbac_subject_roles(role_id); +CREATE INDEX idx_c77_rbac_subject_roles_scope ON public.c77_rbac_subject_roles(scope_type, scope_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 + IF p_external_id IS NULL THEN + RAISE EXCEPTION 'external_id cannot be NULL'; + END IF; + + IF p_role_name IS NULL THEN + RAISE EXCEPTION 'role_name cannot be NULL'; + END IF; + + IF p_scope_type IS NULL THEN + RAISE EXCEPTION 'scope_type cannot be NULL'; + END IF; + + IF p_scope_id IS NULL THEN + RAISE EXCEPTION 'scope_id cannot be NULL'; + END IF; + + -- Insert or get subject + 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 or get role + 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; + + -- Assign role to subject with scope + 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 + IF p_role_name IS NULL THEN + RAISE EXCEPTION 'role_name cannot be NULL'; + END IF; + + IF p_feature_name IS NULL THEN + RAISE EXCEPTION 'feature_name cannot be NULL'; + END IF; + + -- Insert or get role + 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 or get feature + 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; + + -- Grant feature to role + 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 + RETURN FALSE; -- Changed from exception to false for RLS usage + END IF; + + -- Check for global admin access (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.feature_id -- Fixed: was 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; + + -- Check regular access with exact scope match + 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.feature_id -- Fixed: was 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 STABLE; + +-- Function: c77_rbac_apply_policy (simplified version) +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; + v_policy_exists BOOLEAN; +BEGIN + -- Split schema and table name + IF position('.' IN p_table_name) > 0 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; + + -- Check if policy exists + SELECT EXISTS ( + SELECT 1 FROM pg_policies + WHERE schemaname = v_schema_name + AND tablename = v_table_name + AND policyname = 'c77_rbac_policy' + ) INTO v_policy_exists; + + -- Drop existing policy if it exists + IF v_policy_exists THEN + EXECUTE format('DROP POLICY c77_rbac_policy ON %I.%I', v_schema_name, v_table_name); + END IF; + + -- Create the new policy - simplified column reference + 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 + ) + )', + v_schema_name, v_table_name, p_feature_name, p_scope_type, 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); + + RAISE NOTICE 'Applied RLS policy to %.%', v_schema_name, v_table_name; +END; +$$ LANGUAGE plpgsql SECURITY DEFINER; + +-- Grant necessary permissions +GRANT USAGE ON SCHEMA public 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; + +-- Grant table permissions with more restrictions +GRANT SELECT 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; + +-- Only allow modifications through functions +REVOKE 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 + FROM PUBLIC; \ No newline at end of file diff --git a/c77_rbac--1.1.0.sql b/c77_rbac--1.1.0.sql.backup similarity index 100% rename from c77_rbac--1.1.0.sql rename to c77_rbac--1.1.0.sql.backup diff --git a/c77_rbac.control b/c77_rbac.control index 9bfde1d..baacddb 100644 --- a/c77_rbac.control +++ b/c77_rbac.control @@ -1,5 +1,6 @@ -# /usr/share/postgresql/17/extension/c77_rbac.control -comment = 'Agnostic RBAC system for PostgreSQL' -default_version = '1.1.0' -module_pathname = '$libdir/c77_rbac' -relocatable = true +# c77_rbac extension +comment = 'Role-Based Access Control with Row Level Security for PostgreSQL' +default_version = '1.0' +relocatable = false +schema = public +superuser = false