c77_rbac/c77_rbac--1.0.0.sql

144 lines
5.2 KiB
PL/PgSQL

-- /usr/share/postgresql/17/extension/c77_rbac--1.0.sql
\echo Use "CREATE EXTENSION c77_rbac" to load this file. \quit
CREATE TABLE public.c77_rbac_subjects (
subject_id BIGSERIAL PRIMARY KEY,
external_id TEXT UNIQUE NOT NULL,
scope_type TEXT,
scope_id TEXT
);
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),
role_id BIGINT REFERENCES public.c77_rbac_roles(role_id),
scope_type TEXT,
scope_id TEXT,
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),
feature_id BIGINT REFERENCES public.c77_rbac_features(feature_id),
PRIMARY KEY (role_id, feature_id)
);
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
INSERT INTO public.c77_rbac_subjects (external_id, scope_type, scope_id)
VALUES (p_external_id, p_scope_type, p_scope_id)
ON CONFLICT (external_id) DO UPDATE
SET scope_type = EXCLUDED.scope_type,
scope_id = EXCLUDED.scope_id
RETURNING subject_id INTO v_subject_id;
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 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;
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 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 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;
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;
CREATE OR REPLACE FUNCTION public.c77_rbac_can_access(
p_feature_name TEXT,
p_external_id TEXT,
p_scope_type TEXT DEFAULT NULL,
p_scope_id TEXT DEFAULT NULL
) RETURNS BOOLEAN AS $$
BEGIN
IF p_external_id IS NULL THEN
RAISE EXCEPTION 'p_external_id must be provided';
END IF;
-- Admin bypass
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
WHERE s.external_id = p_external_id
AND r.name = 'admin'
AND f.name = p_feature_name
) THEN
RETURN TRUE;
END IF;
RETURN EXISTS (
SELECT 1
FROM public.c77_rbac_subjects s
JOIN public.c77_rbac_subject_roles sr ON s.subject_id = sr.subject_id
AND (p_scope_type IS NULL OR sr.scope_type = p_scope_type)
AND (p_scope_id IS NULL OR sr.scope_id = p_scope_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
WHERE s.external_id = p_external_id
AND f.name = p_feature_name
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;