- Add database schema for violations, appeals, and ban management - Create violation tiers (hard vs soft violations) - Implement automatic violation detection and user ban logic - Add appeal service with monthly limits and deadlines - Create appeal handler for user and admin interfaces - Add API routes for violation management and appeals - Update moderation service to auto-create violations - Support evidence uploads and appeal context - Track violation history and patterns for ban decisions This creates a complete user-facing appeal system where: - Hard violations (hate speech, slurs) = no appeal - Soft violations (gray areas) = appealable with limits - Too many violations = automatic ban - Users can track violation history in settings - Admins can review appeals in Directus
193 lines
8.5 KiB
PL/PgSQL
193 lines
8.5 KiB
PL/PgSQL
-- User Appeal System Migration
|
|
-- Creates tables for tracking user violations, appeals, and ban management
|
|
|
|
-- User Violations Table
|
|
CREATE TABLE IF NOT EXISTS user_violations (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
moderation_flag_id UUID NOT NULL REFERENCES moderation_flags(id) ON DELETE CASCADE,
|
|
violation_type VARCHAR(20) NOT NULL CHECK (violation_type IN ('hard_violation', 'soft_violation')),
|
|
violation_reason TEXT NOT NULL,
|
|
severity_score DECIMAL(3,2) NOT NULL CHECK (severity_score >= 0.0 AND severity_score <= 1.0),
|
|
is_appealable BOOLEAN NOT NULL DEFAULT false,
|
|
appeal_deadline TIMESTAMP WITH TIME ZONE,
|
|
status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'appealed', 'upheld', 'overturned', 'expired')),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
-- User Appeals Table
|
|
CREATE TABLE IF NOT EXISTS user_appeals (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_violation_id UUID NOT NULL REFERENCES user_violations(id) ON DELETE CASCADE,
|
|
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
appeal_reason TEXT NOT NULL,
|
|
appeal_context TEXT,
|
|
evidence_urls JSONB DEFAULT '[]',
|
|
status VARCHAR(20) NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'reviewing', 'approved', 'rejected', 'withdrawn')),
|
|
reviewed_by UUID REFERENCES directus_users(id),
|
|
review_decision TEXT,
|
|
reviewed_at TIMESTAMP WITH TIME ZONE,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
-- User Violation History (for tracking patterns)
|
|
CREATE TABLE IF NOT EXISTS user_violation_history (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
violation_date DATE NOT NULL,
|
|
total_violations INTEGER NOT NULL DEFAULT 0,
|
|
hard_violations INTEGER NOT NULL DEFAULT 0,
|
|
soft_violations INTEGER NOT NULL DEFAULT 0,
|
|
appeals_filed INTEGER NOT NULL DEFAULT 0,
|
|
appeals_upheld INTEGER NOT NULL DEFAULT 0,
|
|
appeals_overturned INTEGER NOT NULL DEFAULT 0,
|
|
current_status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (current_status IN ('active', 'suspended', 'banned')),
|
|
ban_expiry TIMESTAMP WITH TIME ZONE,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
UNIQUE(user_id, violation_date)
|
|
);
|
|
|
|
-- Appeal Guidelines (configurable rules)
|
|
CREATE TABLE IF NOT EXISTS appeal_guidelines (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
violation_type VARCHAR(20) NOT NULL,
|
|
max_appeals_per_month INTEGER NOT NULL DEFAULT 3,
|
|
appeal_window_hours INTEGER NOT NULL DEFAULT 72,
|
|
auto_ban_threshold INTEGER NOT NULL DEFAULT 5,
|
|
hard_violation_ban_threshold INTEGER NOT NULL DEFAULT 2,
|
|
is_active BOOLEAN NOT NULL DEFAULT true,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
|
);
|
|
|
|
-- Insert default appeal guidelines
|
|
INSERT INTO appeal_guidelines (violation_type, max_appeals_per_month, appeal_window_hours, auto_ban_threshold, hard_violation_ban_threshold)
|
|
VALUES
|
|
('hard_violation', 0, 0, 5, 2),
|
|
('soft_violation', 3, 72, 8, 3)
|
|
ON CONFLICT DO NOTHING;
|
|
|
|
-- Indexes for performance
|
|
CREATE INDEX IF NOT EXISTS idx_user_violations_user_id ON user_violations(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_user_violations_status ON user_violations(status);
|
|
CREATE INDEX IF NOT EXISTS idx_user_violations_created_at ON user_violations(created_at);
|
|
CREATE INDEX IF NOT EXISTS idx_user_appeals_user_id ON user_appeals(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_user_appeals_status ON user_appeals(status);
|
|
CREATE INDEX IF NOT EXISTS idx_user_violation_history_user_id ON user_violation_history(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_user_violation_history_date ON user_violation_history(violation_date);
|
|
|
|
-- Functions to automatically detect violation type and create violations
|
|
CREATE OR REPLACE FUNCTION create_user_violation(
|
|
p_user_id UUID,
|
|
p_moderation_flag_id UUID,
|
|
p_flag_reason TEXT,
|
|
p_scores JSONB
|
|
) RETURNS UUID AS $$
|
|
DECLARE
|
|
v_violation_id UUID;
|
|
v_violation_type TEXT;
|
|
v_severity DECIMAL;
|
|
v_is_appealable BOOLEAN;
|
|
v_appeal_deadline TIMESTAMP WITH TIME ZONE;
|
|
BEGIN
|
|
-- Determine violation type based on scores and reason
|
|
CASE
|
|
WHEN p_flag_reason IN ('hate') AND (p_scores->>'hate')::DECIMAL > 0.8 THEN
|
|
BEGIN
|
|
v_violation_type := 'hard_violation';
|
|
v_severity := (p_scores->>'hate')::DECIMAL;
|
|
v_is_appealable := false;
|
|
v_appeal_deadline := NULL;
|
|
END;
|
|
WHEN p_flag_reason IN ('hate', 'violence', 'sexual') AND (p_scores->>'hate')::DECIMAL > 0.6 THEN
|
|
BEGIN
|
|
v_violation_type := 'hard_violation';
|
|
v_severity := GREATEST((p_scores->>'hate')::DECIMAL, (p_scores->>'greed')::DECIMAL, (p_scores->>'delusion')::DECIMAL);
|
|
v_is_appealable := false;
|
|
v_appeal_deadline := NULL;
|
|
END;
|
|
ELSE
|
|
BEGIN
|
|
v_violation_type := 'soft_violation';
|
|
v_severity := GREATEST((p_scores->>'hate')::DECIMAL, (p_scores->>'greed')::DECIMAL, (p_scores->>'delusion')::DECIMAL);
|
|
v_is_appealable := true;
|
|
v_appeal_deadline := NOW() + (SELECT appeal_window_hours FROM appeal_guidelines WHERE violation_type = 'soft_violation' AND is_active = true LIMIT 1) * INTERVAL '1 hour';
|
|
END;
|
|
END CASE;
|
|
|
|
-- Create the violation record
|
|
INSERT INTO user_violations (user_id, moderation_flag_id, violation_type, violation_reason, severity_score, is_appealable, appeal_deadline)
|
|
VALUES (p_user_id, p_moderation_flag_id, v_violation_type, p_flag_reason, v_severity, v_is_appealable, v_appeal_deadline)
|
|
RETURNING id INTO v_violation_id;
|
|
|
|
-- Update violation history
|
|
INSERT INTO user_violation_history (user_id, violation_date, total_violations, hard_violations, soft_violations)
|
|
VALUES (p_user_id, CURRENT_DATE, 1,
|
|
CASE WHEN v_violation_type = 'hard_violation' THEN 1 ELSE 0 END,
|
|
CASE WHEN v_violation_type = 'soft_violation' THEN 1 ELSE 0 END)
|
|
ON CONFLICT (user_id, violation_date)
|
|
DO UPDATE SET
|
|
total_violations = user_violation_history.total_violations + 1,
|
|
hard_violations = user_violation_history.hard_violations + CASE WHEN v_violation_type = 'hard_violation' THEN 1 ELSE 0 END,
|
|
soft_violations = user_violation_history.soft_violations + CASE WHEN v_violation_type = 'soft_violation' THEN 1 ELSE 0 END,
|
|
updated_at = NOW();
|
|
|
|
-- Check for auto-ban conditions
|
|
PERFORM check_user_ban_status(p_user_id);
|
|
|
|
RETURN v_violation_id;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Function to check if user should be banned
|
|
CREATE OR REPLACE FUNCTION check_user_ban_status(p_user_id UUID) RETURNS BOOLEAN AS $$
|
|
DECLARE
|
|
v_hard_count INTEGER;
|
|
v_total_count INTEGER;
|
|
v_ban_threshold INTEGER;
|
|
v_hard_ban_threshold INTEGER;
|
|
BEGIN
|
|
-- Get counts from last 30 days
|
|
SELECT COUNT(*), SUM(CASE WHEN violation_type = 'hard_violation' THEN 1 ELSE 0 END)
|
|
INTO v_total_count, v_hard_count
|
|
FROM user_violations
|
|
WHERE user_id = p_user_id
|
|
AND created_at >= NOW() - INTERVAL '30 days';
|
|
|
|
-- Get thresholds
|
|
SELECT auto_ban_threshold, hard_violation_ban_threshold
|
|
INTO v_ban_threshold, v_hard_ban_threshold
|
|
FROM appeal_guidelines
|
|
WHERE is_active = true
|
|
LIMIT 1;
|
|
|
|
-- Check ban conditions
|
|
IF v_hard_count >= v_hard_ban_threshold OR v_total_count >= v_ban_threshold THEN
|
|
-- Ban the user
|
|
UPDATE users
|
|
SET status = 'banned', updated_at = NOW()
|
|
WHERE id = p_user_id;
|
|
|
|
-- Update violation history
|
|
UPDATE user_violation_history
|
|
SET current_status = 'banned', updated_at = NOW()
|
|
WHERE user_id = p_user_id AND violation_date = CURRENT_DATE;
|
|
|
|
RETURN true;
|
|
END IF;
|
|
|
|
RETURN false;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Add to Directus collections
|
|
INSERT INTO directus_collections (collection, icon, note, hidden, singleton) VALUES
|
|
('user_violations', 'warning', 'User violations and moderation records', false, false),
|
|
('user_appeals', 'gavel', 'User appeals for moderation decisions', false, false),
|
|
('user_violation_history', 'history', 'Daily violation history for users', false, false),
|
|
('appeal_guidelines', 'settings', 'Configurable appeal system guidelines', false, false)
|
|
ON CONFLICT (collection) DO NOTHING;
|