c77_rbac/schema.sql

188 lines
6.8 KiB
PL/PgSQL

-- Core tables for c77_rbac
CREATE TABLE public.c77_rbac_users (
user_id BIGSERIAL PRIMARY KEY,
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_id TEXT,
PRIMARY KEY (user_id, role_id, scope_type, scope_id)
);
CREATE TABLE public.c77_rbac_features (
feature_id BIGSERIAL PRIMARY KEY,
name TEXT NOT NULL UNIQUE
);
CREATE TABLE public.c77_rbac_role_features (
role_id BIGINT NOT NULL REFERENCES public.c77_rbac_roles(role_id),
feature_id BIGINT NOT NULL REFERENCES public.c77_rbac_features(feature_id),
PRIMARY KEY (role_id, feature_id)
);
CREATE TABLE public.c77_rbac_entities (
entity_id BIGSERIAL PRIMARY KEY,
entity_type TEXT NOT NULL,
entity_name TEXT NOT NULL,
parent_id BIGINT REFERENCES public.c77_rbac_entities(entity_id),
UNIQUE (entity_type, entity_name)
);
CREATE OR REPLACE FUNCTION public.c77_rbac_assign_user(
p_username TEXT,
p_role_name TEXT,
p_scope_type TEXT,
p_scope_id TEXT
) RETURNS VOID AS $$
DECLARE
v_user_id BIGINT;
v_role_id BIGINT;
BEGIN
-- Insert or get user
INSERT INTO public.c77_rbac_users (username, scope_type, scope_id)
VALUES (p_username, p_scope_type, p_scope_id)
ON CONFLICT (username) DO UPDATE
SET scope_type = EXCLUDED.scope_type,
scope_id = EXCLUDED.scope_id
RETURNING user_id INTO v_user_id;
-- 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 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;
-- Assign role to user with scope
INSERT INTO public.c77_rbac_user_roles (user_id, role_id, scope_type, scope_id)
VALUES (v_user_id, v_role_id, p_scope_type, p_scope_id)
ON CONFLICT (user_id, role_id, scope_type, scope_id) DO NOTHING;
END;
$$ LANGUAGE plpgsql;
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
-- 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;
CREATE OR REPLACE FUNCTION public.c77_rbac_can_access(
p_username TEXT,
p_feature_name TEXT,
p_scope_type TEXT DEFAULT NULL,
p_scope_id TEXT DEFAULT NULL
) RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1
FROM public.c77_rbac_users u
JOIN public.c77_rbac_user_roles ur ON u.user_id = ur.user_id
JOIN public.c77_rbac_roles r ON ur.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
WHERE u.username = p_username
AND f.name = p_feature_name
AND (p_scope_type IS NULL OR u.scope_type = p_scope_type)
AND (p_scope_id IS NULL OR u.scope_id = p_scope_id)
);
END;
$$ 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(
p_schema_name TEXT,
p_table_name TEXT,
p_feature_name TEXT,
p_scope_column TEXT DEFAULT 'campus'
) RETURNS VOID AS $$
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);
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);
RAISE NOTICE 'Creating policy on %.% with feature %, scope column %', p_schema_name, p_table_name, p_feature_name, p_scope_column;
EXECUTE format(
'CREATE POLICY rbac_policy ON %I.%I FOR ALL TO PUBLIC USING (
c77_rbac.can_access(c77_rbac_get_current_user(), %L, ''campus'', %I)
)',
p_schema_name, p_table_name, p_feature_name, p_scope_column
);
END;
$$ 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 permissions on functions
GRANT EXECUTE ON FUNCTION public.c77_rbac_assign_user(TEXT, TEXT, TEXT, TEXT) TO PUBLIC;
GRANT EXECUTE ON FUNCTION public.c77_rbac_grant_feature(TEXT, TEXT) 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;