mirror of
https://codeberg.org/likwid/likwid.git
synced 2026-02-10 05:23:09 +00:00
193 lines
6.2 KiB
MySQL
193 lines
6.2 KiB
MySQL
|
|
-- Approval workflows for user registration and community creation
|
||
|
|
-- Supports "approval" mode for registration_mode and platform_mode settings
|
||
|
|
|
||
|
|
-- Pending user registrations (for approval mode)
|
||
|
|
CREATE TABLE pending_registrations (
|
||
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||
|
|
|
||
|
|
-- User data (not yet in users table)
|
||
|
|
username VARCHAR(255) NOT NULL,
|
||
|
|
email VARCHAR(255) NOT NULL,
|
||
|
|
password_hash VARCHAR(255) NOT NULL,
|
||
|
|
display_name VARCHAR(255),
|
||
|
|
|
||
|
|
-- Invitation used (if any)
|
||
|
|
invitation_id UUID REFERENCES invitations(id) ON DELETE SET NULL,
|
||
|
|
|
||
|
|
-- Approval workflow
|
||
|
|
status VARCHAR(50) DEFAULT 'pending' CHECK (status IN ('pending', 'approved', 'rejected')),
|
||
|
|
reviewed_by UUID REFERENCES users(id) ON DELETE SET NULL,
|
||
|
|
reviewed_at TIMESTAMPTZ,
|
||
|
|
rejection_reason TEXT,
|
||
|
|
|
||
|
|
-- Timestamps
|
||
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||
|
|
expires_at TIMESTAMPTZ DEFAULT NOW() + INTERVAL '7 days',
|
||
|
|
|
||
|
|
-- Prevent duplicates
|
||
|
|
UNIQUE(username),
|
||
|
|
UNIQUE(email)
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Pending community creation requests (for approval mode)
|
||
|
|
CREATE TABLE pending_communities (
|
||
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||
|
|
|
||
|
|
-- Community data (not yet in communities table)
|
||
|
|
name VARCHAR(255) NOT NULL,
|
||
|
|
slug VARCHAR(255) NOT NULL,
|
||
|
|
description TEXT,
|
||
|
|
|
||
|
|
-- Requester
|
||
|
|
requested_by UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||
|
|
|
||
|
|
-- Approval workflow
|
||
|
|
status VARCHAR(50) DEFAULT 'pending' CHECK (status IN ('pending', 'approved', 'rejected')),
|
||
|
|
reviewed_by UUID REFERENCES users(id) ON DELETE SET NULL,
|
||
|
|
reviewed_at TIMESTAMPTZ,
|
||
|
|
rejection_reason TEXT,
|
||
|
|
|
||
|
|
-- Timestamps
|
||
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||
|
|
|
||
|
|
-- Prevent duplicate requests
|
||
|
|
UNIQUE(slug)
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Indexes
|
||
|
|
CREATE INDEX idx_pending_registrations_status ON pending_registrations(status);
|
||
|
|
CREATE INDEX idx_pending_registrations_email ON pending_registrations(email);
|
||
|
|
CREATE INDEX idx_pending_registrations_created ON pending_registrations(created_at DESC);
|
||
|
|
|
||
|
|
CREATE INDEX idx_pending_communities_status ON pending_communities(status);
|
||
|
|
CREATE INDEX idx_pending_communities_requested_by ON pending_communities(requested_by);
|
||
|
|
CREATE INDEX idx_pending_communities_created ON pending_communities(created_at DESC);
|
||
|
|
|
||
|
|
-- Function to approve a registration
|
||
|
|
CREATE OR REPLACE FUNCTION approve_registration(
|
||
|
|
p_pending_id UUID,
|
||
|
|
p_reviewer_id UUID
|
||
|
|
) RETURNS UUID AS $$
|
||
|
|
DECLARE
|
||
|
|
v_pending pending_registrations%ROWTYPE;
|
||
|
|
v_user_id UUID;
|
||
|
|
v_user_count BIGINT;
|
||
|
|
BEGIN
|
||
|
|
-- Get pending registration
|
||
|
|
SELECT * INTO v_pending FROM pending_registrations WHERE id = p_pending_id AND status = 'pending';
|
||
|
|
IF NOT FOUND THEN
|
||
|
|
RAISE EXCEPTION 'Pending registration not found or already processed';
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
-- Check if expired
|
||
|
|
IF v_pending.expires_at < NOW() THEN
|
||
|
|
UPDATE pending_registrations SET status = 'rejected', rejection_reason = 'Expired' WHERE id = p_pending_id;
|
||
|
|
RAISE EXCEPTION 'Registration request has expired';
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
-- Check if first user (should be admin)
|
||
|
|
SELECT COUNT(*) INTO v_user_count FROM users;
|
||
|
|
|
||
|
|
-- Create the user
|
||
|
|
INSERT INTO users (username, email, password_hash, display_name, is_admin, invited_by)
|
||
|
|
VALUES (v_pending.username, v_pending.email, v_pending.password_hash, v_pending.display_name, v_user_count = 0, v_pending.invitation_id)
|
||
|
|
RETURNING id INTO v_user_id;
|
||
|
|
|
||
|
|
-- Use invitation if provided
|
||
|
|
IF v_pending.invitation_id IS NOT NULL THEN
|
||
|
|
PERFORM use_invitation(
|
||
|
|
(SELECT code FROM invitations WHERE id = v_pending.invitation_id),
|
||
|
|
v_user_id,
|
||
|
|
v_pending.email
|
||
|
|
);
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
-- Mark as approved
|
||
|
|
UPDATE pending_registrations
|
||
|
|
SET status = 'approved', reviewed_by = p_reviewer_id, reviewed_at = NOW()
|
||
|
|
WHERE id = p_pending_id;
|
||
|
|
|
||
|
|
RETURN v_user_id;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
-- Function to reject a registration
|
||
|
|
CREATE OR REPLACE FUNCTION reject_registration(
|
||
|
|
p_pending_id UUID,
|
||
|
|
p_reviewer_id UUID,
|
||
|
|
p_reason TEXT DEFAULT NULL
|
||
|
|
) RETURNS BOOLEAN AS $$
|
||
|
|
BEGIN
|
||
|
|
UPDATE pending_registrations
|
||
|
|
SET status = 'rejected',
|
||
|
|
reviewed_by = p_reviewer_id,
|
||
|
|
reviewed_at = NOW(),
|
||
|
|
rejection_reason = p_reason
|
||
|
|
WHERE id = p_pending_id AND status = 'pending';
|
||
|
|
|
||
|
|
RETURN FOUND;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
-- Function to approve a community
|
||
|
|
CREATE OR REPLACE FUNCTION approve_community(
|
||
|
|
p_pending_id UUID,
|
||
|
|
p_reviewer_id UUID
|
||
|
|
) RETURNS UUID AS $$
|
||
|
|
DECLARE
|
||
|
|
v_pending pending_communities%ROWTYPE;
|
||
|
|
v_community_id UUID;
|
||
|
|
BEGIN
|
||
|
|
-- Get pending community
|
||
|
|
SELECT * INTO v_pending FROM pending_communities WHERE id = p_pending_id AND status = 'pending';
|
||
|
|
IF NOT FOUND THEN
|
||
|
|
RAISE EXCEPTION 'Pending community not found or already processed';
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
-- Create the community
|
||
|
|
INSERT INTO communities (name, slug, description, created_by, is_active)
|
||
|
|
VALUES (v_pending.name, v_pending.slug, v_pending.description, v_pending.requested_by, true)
|
||
|
|
RETURNING id INTO v_community_id;
|
||
|
|
|
||
|
|
-- Add requester as admin
|
||
|
|
INSERT INTO community_members (community_id, user_id, role)
|
||
|
|
VALUES (v_community_id, v_pending.requested_by, 'admin');
|
||
|
|
|
||
|
|
-- Mark as approved
|
||
|
|
UPDATE pending_communities
|
||
|
|
SET status = 'approved', reviewed_by = p_reviewer_id, reviewed_at = NOW()
|
||
|
|
WHERE id = p_pending_id;
|
||
|
|
|
||
|
|
RETURN v_community_id;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
-- Function to reject a community
|
||
|
|
CREATE OR REPLACE FUNCTION reject_community(
|
||
|
|
p_pending_id UUID,
|
||
|
|
p_reviewer_id UUID,
|
||
|
|
p_reason TEXT DEFAULT NULL
|
||
|
|
) RETURNS BOOLEAN AS $$
|
||
|
|
BEGIN
|
||
|
|
UPDATE pending_communities
|
||
|
|
SET status = 'rejected',
|
||
|
|
reviewed_by = p_reviewer_id,
|
||
|
|
reviewed_at = NOW(),
|
||
|
|
rejection_reason = p_reason
|
||
|
|
WHERE id = p_pending_id AND status = 'pending';
|
||
|
|
|
||
|
|
RETURN FOUND;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
-- Cleanup expired pending registrations (to be run periodically)
|
||
|
|
CREATE OR REPLACE FUNCTION cleanup_expired_pending_registrations() RETURNS INTEGER AS $$
|
||
|
|
DECLARE
|
||
|
|
deleted_count INTEGER;
|
||
|
|
BEGIN
|
||
|
|
DELETE FROM pending_registrations WHERE expires_at < NOW() AND status = 'pending';
|
||
|
|
GET DIAGNOSTICS deleted_count = ROW_COUNT;
|
||
|
|
RETURN deleted_count;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|