-- Core tables for c77_rbac CREATE TABLE c77_rbac_users ( user_id UUID PRIMARY KEY DEFAULT gen_random_uuid(), username TEXT NOT NULL, scope_type TEXT, scope_id TEXT, CONSTRAINT c77_rbac_unique_user_scope UNIQUE (username, scope_type, scope_id) ); CREATE TABLE c77_rbac_roles ( role_id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL UNIQUE ); CREATE TABLE c77_rbac_user_roles ( user_id UUID REFERENCES c77_rbac_users(user_id), role_id UUID REFERENCES c77_rbac_roles(role_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) ); -- Optional hierarchy table CREATE TABLE c77_rbac_entities ( entity_id UUID PRIMARY KEY DEFAULT gen_random_uuid(), type TEXT NOT NULL, name TEXT NOT NULL, parent_id UUID REFERENCES c77_rbac_entities(entity_id), CONSTRAINT c77_rbac_unique_entity UNIQUE (type, name) ); CREATE FUNCTION 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 UUID; v_role_id UUID; BEGIN -- Insert or update user with scope INSERT INTO c77_rbac_users (username, scope_type, scope_id) VALUES (p_username, p_scope_type, p_scope_id) ON CONFLICT ON CONSTRAINT c77_rbac_unique_user_scope DO UPDATE SET scope_type = EXCLUDED.scope_type, scope_id = EXCLUDED.scope_id RETURNING user_id INTO v_user_id; -- Get or create role SELECT role_id INTO v_role_id FROM c77_rbac_roles WHERE name = p_role_name; IF v_role_id IS NULL THEN INSERT INTO c77_rbac_roles (name) VALUES (p_role_name) RETURNING role_id INTO v_role_id; END IF; -- Link user to role INSERT INTO c77_rbac_user_roles (user_id, role_id) VALUES (v_user_id, v_role_id) ON CONFLICT DO NOTHING; END; $$ LANGUAGE plpgsql; CREATE FUNCTION c77_rbac_grant_feature( p_role_name TEXT, p_feature_name TEXT ) RETURNS VOID AS $$ DECLARE v_role_id UUID; v_feature_id UUID; BEGIN -- Get or create role SELECT role_id INTO v_role_id FROM c77_rbac_roles WHERE name = p_role_name; IF v_role_id IS NULL THEN INSERT INTO c77_rbac_roles (name) VALUES (p_role_name) RETURNING role_id INTO v_role_id; END IF; -- Get or create feature INSERT INTO c77_rbac_features (name) VALUES (p_feature_name) ON CONFLICT (name) DO UPDATE SET name = EXCLUDED.name RETURNING feature_id INTO v_feature_id; -- Link role to feature INSERT INTO c77_rbac_role_features (role_id, feature_id) VALUES (v_role_id, v_feature_id) ON CONFLICT DO NOTHING; END; $$ LANGUAGE plpgsql;