mirror of
https://codeberg.org/likwid/likwid.git
synced 2026-02-09 21:13:09 +00:00
203 lines
8.7 KiB
MySQL
203 lines
8.7 KiB
MySQL
|
|
-- Core Role/Permission System
|
||
|
|
-- Provides granular access control with default roles and custom role support
|
||
|
|
|
||
|
|
-- Permission categories
|
||
|
|
CREATE TYPE permission_category AS ENUM (
|
||
|
|
'platform', -- Platform-wide permissions
|
||
|
|
'community', -- Community management
|
||
|
|
'proposals', -- Proposal lifecycle
|
||
|
|
'voting', -- Voting configuration
|
||
|
|
'moderation', -- Content moderation
|
||
|
|
'plugins', -- Plugin management
|
||
|
|
'users', -- User management
|
||
|
|
'integrations' -- External integrations
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Core permissions table
|
||
|
|
CREATE TABLE permissions (
|
||
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||
|
|
name VARCHAR(100) NOT NULL UNIQUE,
|
||
|
|
category permission_category NOT NULL,
|
||
|
|
description TEXT,
|
||
|
|
is_system BOOLEAN NOT NULL DEFAULT FALSE, -- System permissions can't be deleted
|
||
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Roles table (platform-level and community-level)
|
||
|
|
CREATE TABLE roles (
|
||
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||
|
|
name VARCHAR(100) NOT NULL,
|
||
|
|
display_name VARCHAR(100) NOT NULL,
|
||
|
|
description TEXT,
|
||
|
|
color VARCHAR(7), -- Hex color for UI
|
||
|
|
community_id UUID REFERENCES communities(id) ON DELETE CASCADE, -- NULL = platform role
|
||
|
|
is_system BOOLEAN NOT NULL DEFAULT FALSE, -- System roles can't be deleted
|
||
|
|
is_default BOOLEAN NOT NULL DEFAULT FALSE, -- Default role for new members
|
||
|
|
priority INT NOT NULL DEFAULT 0, -- Higher = more authority (for display/conflict resolution)
|
||
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
UNIQUE(name, community_id)
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Role permissions (many-to-many)
|
||
|
|
CREATE TABLE role_permissions (
|
||
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||
|
|
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE,
|
||
|
|
permission_id UUID NOT NULL REFERENCES permissions(id) ON DELETE CASCADE,
|
||
|
|
granted BOOLEAN NOT NULL DEFAULT TRUE, -- Can explicitly deny
|
||
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
UNIQUE(role_id, permission_id)
|
||
|
|
);
|
||
|
|
|
||
|
|
-- User roles (many-to-many, scoped to community or platform)
|
||
|
|
CREATE TABLE user_roles (
|
||
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||
|
|
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||
|
|
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE,
|
||
|
|
community_id UUID REFERENCES communities(id) ON DELETE CASCADE, -- NULL = platform role
|
||
|
|
granted_by UUID REFERENCES users(id),
|
||
|
|
granted_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
expires_at TIMESTAMPTZ, -- Optional expiration
|
||
|
|
UNIQUE(user_id, role_id, community_id)
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Insert default permissions
|
||
|
|
INSERT INTO permissions (name, category, description, is_system) VALUES
|
||
|
|
-- Platform permissions
|
||
|
|
('platform.admin', 'platform', 'Full platform administration access', TRUE),
|
||
|
|
('platform.settings', 'platform', 'Manage platform settings', TRUE),
|
||
|
|
('platform.users.view', 'users', 'View all users', TRUE),
|
||
|
|
('platform.users.manage', 'users', 'Manage user accounts', TRUE),
|
||
|
|
('platform.users.ban', 'users', 'Ban/suspend users', TRUE),
|
||
|
|
|
||
|
|
-- Community permissions
|
||
|
|
('community.create', 'community', 'Create new communities', TRUE),
|
||
|
|
('community.settings', 'community', 'Manage community settings', TRUE),
|
||
|
|
('community.members.view', 'community', 'View community members', TRUE),
|
||
|
|
('community.members.manage', 'community', 'Manage community membership', TRUE),
|
||
|
|
('community.members.invite', 'community', 'Invite new members', TRUE),
|
||
|
|
('community.roles.manage', 'community', 'Create and manage roles', TRUE),
|
||
|
|
|
||
|
|
-- Proposal permissions
|
||
|
|
('proposals.create', 'proposals', 'Create proposals', TRUE),
|
||
|
|
('proposals.edit.own', 'proposals', 'Edit own proposals', TRUE),
|
||
|
|
('proposals.edit.any', 'proposals', 'Edit any proposal', TRUE),
|
||
|
|
('proposals.delete.own', 'proposals', 'Delete own proposals', TRUE),
|
||
|
|
('proposals.delete.any', 'proposals', 'Delete any proposal', TRUE),
|
||
|
|
('proposals.moderate', 'proposals', 'Moderate proposal lifecycle', TRUE),
|
||
|
|
|
||
|
|
-- Voting permissions
|
||
|
|
('voting.vote', 'voting', 'Cast votes', TRUE),
|
||
|
|
('voting.configure', 'voting', 'Configure voting methods', TRUE),
|
||
|
|
('voting.methods.manage', 'voting', 'Enable/disable voting methods', TRUE),
|
||
|
|
('voting.results.view', 'voting', 'View detailed voting results', TRUE),
|
||
|
|
|
||
|
|
-- Moderation permissions
|
||
|
|
('moderation.comments.edit', 'moderation', 'Edit comments', TRUE),
|
||
|
|
('moderation.comments.delete', 'moderation', 'Delete comments', TRUE),
|
||
|
|
('moderation.users.warn', 'moderation', 'Warn users', TRUE),
|
||
|
|
('moderation.users.mute', 'moderation', 'Mute users', TRUE),
|
||
|
|
('moderation.users.kick', 'moderation', 'Remove users from community', TRUE),
|
||
|
|
('moderation.log.view', 'moderation', 'View moderation log', TRUE),
|
||
|
|
|
||
|
|
-- Plugin permissions
|
||
|
|
('plugins.view', 'plugins', 'View installed plugins', TRUE),
|
||
|
|
('plugins.install', 'plugins', 'Install new plugins', TRUE),
|
||
|
|
('plugins.configure', 'plugins', 'Configure plugin settings', TRUE),
|
||
|
|
('plugins.uninstall', 'plugins', 'Uninstall plugins', TRUE),
|
||
|
|
|
||
|
|
-- Delegation permissions
|
||
|
|
('delegation.delegate', 'voting', 'Delegate votes to others', TRUE),
|
||
|
|
('delegation.receive', 'voting', 'Receive delegated votes', TRUE),
|
||
|
|
|
||
|
|
-- Integration permissions
|
||
|
|
('integrations.view', 'integrations', 'View integrations', TRUE),
|
||
|
|
('integrations.configure', 'integrations', 'Configure integrations', TRUE)
|
||
|
|
ON CONFLICT (name) DO NOTHING;
|
||
|
|
|
||
|
|
-- Insert default platform roles
|
||
|
|
INSERT INTO roles (name, display_name, description, is_system, priority, community_id) VALUES
|
||
|
|
('platform_admin', 'Platform Admin', 'Full platform control', TRUE, 1000, NULL),
|
||
|
|
('platform_moderator', 'Platform Moderator', 'Platform-wide moderation', TRUE, 500, NULL),
|
||
|
|
('user', 'User', 'Standard registered user', TRUE, 100, NULL)
|
||
|
|
ON CONFLICT (name, community_id) DO NOTHING;
|
||
|
|
|
||
|
|
-- Assign all permissions to platform_admin
|
||
|
|
INSERT INTO role_permissions (role_id, permission_id, granted)
|
||
|
|
SELECT r.id, p.id, TRUE
|
||
|
|
FROM roles r, permissions p
|
||
|
|
WHERE r.name = 'platform_admin' AND r.community_id IS NULL
|
||
|
|
ON CONFLICT (role_id, permission_id) DO NOTHING;
|
||
|
|
|
||
|
|
-- Assign moderation permissions to platform_moderator
|
||
|
|
INSERT INTO role_permissions (role_id, permission_id, granted)
|
||
|
|
SELECT r.id, p.id, TRUE
|
||
|
|
FROM roles r, permissions p
|
||
|
|
WHERE r.name = 'platform_moderator' AND r.community_id IS NULL
|
||
|
|
AND p.category IN ('moderation', 'community')
|
||
|
|
ON CONFLICT (role_id, permission_id) DO NOTHING;
|
||
|
|
|
||
|
|
-- Assign basic permissions to user role
|
||
|
|
INSERT INTO role_permissions (role_id, permission_id, granted)
|
||
|
|
SELECT r.id, p.id, TRUE
|
||
|
|
FROM roles r, permissions p
|
||
|
|
WHERE r.name = 'user' AND r.community_id IS NULL
|
||
|
|
AND p.name IN ('community.create', 'proposals.create', 'proposals.edit.own',
|
||
|
|
'proposals.delete.own', 'voting.vote', 'delegation.delegate',
|
||
|
|
'community.members.view', 'plugins.view', 'voting.results.view')
|
||
|
|
ON CONFLICT (role_id, permission_id) DO NOTHING;
|
||
|
|
|
||
|
|
-- Indexes
|
||
|
|
CREATE INDEX idx_permissions_category ON permissions(category);
|
||
|
|
CREATE INDEX idx_roles_community ON roles(community_id);
|
||
|
|
CREATE INDEX idx_roles_system ON roles(is_system);
|
||
|
|
CREATE INDEX idx_role_permissions_role ON role_permissions(role_id);
|
||
|
|
CREATE INDEX idx_user_roles_user ON user_roles(user_id);
|
||
|
|
CREATE INDEX idx_user_roles_role ON user_roles(role_id);
|
||
|
|
CREATE INDEX idx_user_roles_community ON user_roles(community_id);
|
||
|
|
|
||
|
|
-- Triggers
|
||
|
|
CREATE TRIGGER roles_updated_at BEFORE UPDATE ON roles
|
||
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at();
|
||
|
|
|
||
|
|
-- Function to check if user has permission
|
||
|
|
CREATE OR REPLACE FUNCTION user_has_permission(
|
||
|
|
p_user_id UUID,
|
||
|
|
p_permission_name VARCHAR,
|
||
|
|
p_community_id UUID DEFAULT NULL
|
||
|
|
) RETURNS BOOLEAN AS $$
|
||
|
|
DECLARE
|
||
|
|
has_perm BOOLEAN := FALSE;
|
||
|
|
BEGIN
|
||
|
|
-- Check platform roles first
|
||
|
|
SELECT EXISTS (
|
||
|
|
SELECT 1 FROM user_roles ur
|
||
|
|
JOIN role_permissions rp ON ur.role_id = rp.role_id
|
||
|
|
JOIN permissions p ON rp.permission_id = p.id
|
||
|
|
WHERE ur.user_id = p_user_id
|
||
|
|
AND p.name = p_permission_name
|
||
|
|
AND rp.granted = TRUE
|
||
|
|
AND ur.community_id IS NULL
|
||
|
|
AND (ur.expires_at IS NULL OR ur.expires_at > NOW())
|
||
|
|
) INTO has_perm;
|
||
|
|
|
||
|
|
IF has_perm THEN RETURN TRUE; END IF;
|
||
|
|
|
||
|
|
-- Check community roles if community_id provided
|
||
|
|
IF p_community_id IS NOT NULL THEN
|
||
|
|
SELECT EXISTS (
|
||
|
|
SELECT 1 FROM user_roles ur
|
||
|
|
JOIN role_permissions rp ON ur.role_id = rp.role_id
|
||
|
|
JOIN permissions p ON rp.permission_id = p.id
|
||
|
|
WHERE ur.user_id = p_user_id
|
||
|
|
AND p.name = p_permission_name
|
||
|
|
AND rp.granted = TRUE
|
||
|
|
AND ur.community_id = p_community_id
|
||
|
|
AND (ur.expires_at IS NULL OR ur.expires_at > NOW())
|
||
|
|
) INTO has_perm;
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
RETURN has_perm;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|