-- ============================================================================ -- SELF-MODERATION RULES PLUGIN -- Configurable community rules with automatic escalation and voting on sanctions -- ============================================================================ -- ============================================================================ -- COMMUNITY RULES -- Configurable rules that communities can define -- ============================================================================ CREATE TYPE rule_severity AS ENUM ('info', 'warning', 'minor', 'major', 'critical'); CREATE TYPE rule_scope AS ENUM ('content', 'behavior', 'voting', 'participation', 'meta'); CREATE TABLE community_rules ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, -- Rule definition code VARCHAR(50) NOT NULL, title VARCHAR(200) NOT NULL, description TEXT NOT NULL, scope rule_scope NOT NULL DEFAULT 'behavior', severity rule_severity NOT NULL DEFAULT 'warning', -- Rule behavior is_active BOOLEAN NOT NULL DEFAULT TRUE, requires_human_review BOOLEAN NOT NULL DEFAULT TRUE, auto_detection_enabled BOOLEAN NOT NULL DEFAULT FALSE, detection_patterns JSONB, -- For automated detection -- Sanctions default_sanction_type VARCHAR(50), default_sanction_duration_hours INT, escalation_multiplier DECIMAL(3,2) NOT NULL DEFAULT 1.5, max_escalation_level INT NOT NULL DEFAULT 3, -- Voting on sanctions allow_community_vote BOOLEAN NOT NULL DEFAULT FALSE, vote_threshold DECIMAL(5,4) NOT NULL DEFAULT 0.6667, -- 2/3 majority vote_quorum DECIMAL(5,4) NOT NULL DEFAULT 0.10, vote_duration_hours INT NOT NULL DEFAULT 48, -- Metadata created_by UUID REFERENCES users(id), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), version INT NOT NULL DEFAULT 1, UNIQUE(community_id, code) ); CREATE INDEX idx_community_rules_community ON community_rules(community_id); CREATE INDEX idx_community_rules_active ON community_rules(community_id, is_active) WHERE is_active = true; CREATE INDEX idx_community_rules_scope ON community_rules(community_id, scope); COMMENT ON TABLE community_rules IS 'Community-defined moderation rules'; -- ============================================================================ -- RULE VIOLATIONS -- Reported or detected rule violations -- ============================================================================ CREATE TYPE violation_status AS ENUM ( 'reported', -- Initial report 'under_review', -- Being reviewed by moderator 'pending_vote', -- Community vote in progress 'confirmed', -- Violation confirmed 'dismissed', -- Report dismissed 'appealed', -- Under appeal 'resolved' -- Sanction applied and completed ); CREATE TABLE rule_violations ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, rule_id UUID NOT NULL REFERENCES community_rules(id), -- Violation details target_user_id UUID NOT NULL REFERENCES users(id), target_content_id UUID, target_content_type VARCHAR(50), -- Reporter reported_by UUID REFERENCES users(id), reported_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), report_reason TEXT, report_evidence JSONB, -- Status tracking status violation_status NOT NULL DEFAULT 'reported', escalation_level INT NOT NULL DEFAULT 0, -- Review reviewed_by UUID REFERENCES users(id), reviewed_at TIMESTAMPTZ, review_notes TEXT, -- Community vote (if applicable) vote_proposal_id UUID REFERENCES proposals(id), vote_started_at TIMESTAMPTZ, vote_ended_at TIMESTAMPTZ, vote_result JSONB, -- Resolution resolved_at TIMESTAMPTZ, resolution_type VARCHAR(50), -- sanction_applied, dismissed, appealed_overturned resolution_notes TEXT, -- Audit created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_rule_violations_community ON rule_violations(community_id); CREATE INDEX idx_rule_violations_target ON rule_violations(target_user_id); CREATE INDEX idx_rule_violations_status ON rule_violations(status); CREATE INDEX idx_rule_violations_rule ON rule_violations(rule_id); CREATE INDEX idx_rule_violations_pending ON rule_violations(community_id, status) WHERE status IN ('reported', 'under_review', 'pending_vote'); COMMENT ON TABLE rule_violations IS 'Tracked rule violations and their resolution'; -- ============================================================================ -- SANCTIONS -- Applied sanctions for violations -- ============================================================================ CREATE TYPE sanction_type AS ENUM ( 'warning', -- Official warning 'content_removal', -- Remove offending content 'temporary_mute', -- Cannot post/comment temporarily 'temporary_suspend', -- Cannot access community temporarily 'voting_suspension', -- Cannot vote temporarily 'permanent_ban', -- Permanent community ban 'custom' -- Custom sanction ); CREATE TYPE sanction_status AS ENUM ( 'pending', -- Awaiting application 'active', -- Currently in effect 'completed', -- Duration expired 'lifted', -- Manually lifted early 'appealed' -- Overturned on appeal ); CREATE TABLE sanctions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), violation_id UUID NOT NULL REFERENCES rule_violations(id), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, target_user_id UUID NOT NULL REFERENCES users(id), -- Sanction details sanction_type sanction_type NOT NULL, severity_level INT NOT NULL DEFAULT 1, description TEXT, -- Duration starts_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), duration_hours INT, expires_at TIMESTAMPTZ, -- Status status sanction_status NOT NULL DEFAULT 'active', -- Applied by applied_by UUID REFERENCES users(id), applied_via VARCHAR(50) NOT NULL DEFAULT 'manual', -- manual, vote, auto -- Lifting/Appeal lifted_at TIMESTAMPTZ, lifted_by UUID REFERENCES users(id), lift_reason TEXT, -- Audit created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), ledger_entry_id UUID -- Reference to moderation ledger ); CREATE INDEX idx_sanctions_violation ON sanctions(violation_id); CREATE INDEX idx_sanctions_target ON sanctions(target_user_id); CREATE INDEX idx_sanctions_community ON sanctions(community_id); CREATE INDEX idx_sanctions_status ON sanctions(status); CREATE INDEX idx_sanctions_active ON sanctions(target_user_id, status, expires_at) WHERE status = 'active'; COMMENT ON TABLE sanctions IS 'Applied sanctions for rule violations'; -- ============================================================================ -- USER VIOLATION HISTORY -- Aggregated view of user's violation history -- ============================================================================ CREATE TABLE user_violation_summary ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, -- Counts total_violations INT NOT NULL DEFAULT 0, confirmed_violations INT NOT NULL DEFAULT 0, dismissed_violations INT NOT NULL DEFAULT 0, -- Sanctions total_sanctions INT NOT NULL DEFAULT 0, active_sanctions INT NOT NULL DEFAULT 0, warnings_count INT NOT NULL DEFAULT 0, mutes_count INT NOT NULL DEFAULT 0, suspensions_count INT NOT NULL DEFAULT 0, -- Escalation tracking current_escalation_level INT NOT NULL DEFAULT 0, last_violation_at TIMESTAMPTZ, last_sanction_at TIMESTAMPTZ, -- Good standing calculation days_since_last_violation INT, is_in_good_standing BOOLEAN NOT NULL DEFAULT TRUE, updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(user_id, community_id) ); CREATE INDEX idx_user_violation_summary_user ON user_violation_summary(user_id); CREATE INDEX idx_user_violation_summary_community ON user_violation_summary(community_id); COMMENT ON TABLE user_violation_summary IS 'Aggregated violation history per user per community'; -- ============================================================================ -- ESCALATION RULES -- Define how sanctions escalate with repeated violations -- ============================================================================ CREATE TABLE escalation_rules ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, rule_id UUID REFERENCES community_rules(id) ON DELETE CASCADE, -- Escalation level level INT NOT NULL, -- Sanction for this level sanction_type sanction_type NOT NULL, duration_hours INT, additional_actions JSONB, -- Conditions cooldown_days INT NOT NULL DEFAULT 90, -- Days before escalation resets created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(community_id, rule_id, level) ); CREATE INDEX idx_escalation_rules_community ON escalation_rules(community_id); CREATE INDEX idx_escalation_rules_rule ON escalation_rules(rule_id); COMMENT ON TABLE escalation_rules IS 'Escalation ladder for repeated violations'; -- ============================================================================ -- HELPER FUNCTIONS -- ============================================================================ -- Calculate escalation level for a user/rule combination CREATE OR REPLACE FUNCTION calculate_escalation_level( p_user_id UUID, p_community_id UUID, p_rule_id UUID ) RETURNS INT AS $$ DECLARE v_level INT; v_cooldown_days INT; BEGIN -- Get the escalation cooldown SELECT COALESCE(MAX(cooldown_days), 90) INTO v_cooldown_days FROM escalation_rules WHERE community_id = p_community_id AND (rule_id = p_rule_id OR rule_id IS NULL); -- Count confirmed violations within cooldown period SELECT COUNT(*) INTO v_level FROM rule_violations WHERE target_user_id = p_user_id AND community_id = p_community_id AND rule_id = p_rule_id AND status = 'confirmed' AND resolved_at > NOW() - (v_cooldown_days || ' days')::INTERVAL; RETURN v_level; END; $$ LANGUAGE plpgsql; -- Get appropriate sanction for escalation level CREATE OR REPLACE FUNCTION get_escalated_sanction( p_community_id UUID, p_rule_id UUID, p_level INT ) RETURNS TABLE ( sanction_type sanction_type, duration_hours INT ) AS $$ BEGIN -- Try rule-specific escalation RETURN QUERY SELECT er.sanction_type, er.duration_hours FROM escalation_rules er WHERE er.community_id = p_community_id AND er.rule_id = p_rule_id AND er.level = p_level LIMIT 1; IF NOT FOUND THEN -- Try community default escalation RETURN QUERY SELECT er.sanction_type, er.duration_hours FROM escalation_rules er WHERE er.community_id = p_community_id AND er.rule_id IS NULL AND er.level = p_level LIMIT 1; END IF; IF NOT FOUND THEN -- Default escalation ladder RETURN QUERY SELECT CASE p_level WHEN 1 THEN 'warning'::sanction_type WHEN 2 THEN 'temporary_mute'::sanction_type WHEN 3 THEN 'temporary_suspend'::sanction_type ELSE 'permanent_ban'::sanction_type END, CASE p_level WHEN 1 THEN NULL::INT WHEN 2 THEN 24 WHEN 3 THEN 168 ELSE NULL END; END IF; END; $$ LANGUAGE plpgsql; -- Apply a sanction CREATE OR REPLACE FUNCTION apply_sanction( p_violation_id UUID, p_sanction_type sanction_type, p_duration_hours INT, p_applied_by UUID, p_applied_via VARCHAR(50) ) RETURNS UUID AS $$ DECLARE v_violation rule_violations%ROWTYPE; v_sanction_id UUID; v_expires_at TIMESTAMPTZ; BEGIN -- Get violation details SELECT * INTO v_violation FROM rule_violations WHERE id = p_violation_id; -- Calculate expiration IF p_duration_hours IS NOT NULL THEN v_expires_at := NOW() + (p_duration_hours || ' hours')::INTERVAL; END IF; -- Create sanction INSERT INTO sanctions ( violation_id, community_id, target_user_id, sanction_type, duration_hours, expires_at, applied_by, applied_via ) VALUES ( p_violation_id, v_violation.community_id, v_violation.target_user_id, p_sanction_type, p_duration_hours, v_expires_at, p_applied_by, p_applied_via ) RETURNING id INTO v_sanction_id; -- Update violation status UPDATE rule_violations SET status = 'resolved', resolved_at = NOW(), resolution_type = 'sanction_applied' WHERE id = p_violation_id; -- Update user summary INSERT INTO user_violation_summary (user_id, community_id, confirmed_violations, total_sanctions, last_sanction_at) VALUES (v_violation.target_user_id, v_violation.community_id, 1, 1, NOW()) ON CONFLICT (user_id, community_id) DO UPDATE SET confirmed_violations = user_violation_summary.confirmed_violations + 1, total_sanctions = user_violation_summary.total_sanctions + 1, last_sanction_at = NOW(), updated_at = NOW(); RETURN v_sanction_id; END; $$ LANGUAGE plpgsql; -- Check and expire sanctions CREATE OR REPLACE FUNCTION expire_sanctions() RETURNS INT AS $$ DECLARE v_count INT; BEGIN UPDATE sanctions SET status = 'completed' WHERE status = 'active' AND expires_at IS NOT NULL AND expires_at < NOW(); GET DIAGNOSTICS v_count = ROW_COUNT; RETURN v_count; END; $$ LANGUAGE plpgsql; -- Check if user has active sanction CREATE OR REPLACE FUNCTION user_has_active_sanction( p_user_id UUID, p_community_id UUID, p_sanction_type sanction_type DEFAULT NULL ) RETURNS BOOLEAN AS $$ BEGIN RETURN EXISTS ( SELECT 1 FROM sanctions WHERE target_user_id = p_user_id AND community_id = p_community_id AND status = 'active' AND (p_sanction_type IS NULL OR sanction_type = p_sanction_type) AND (expires_at IS NULL OR expires_at > NOW()) ); END; $$ LANGUAGE plpgsql; -- ============================================================================ -- DEFAULT ESCALATION RULES -- ============================================================================ -- These will be created per-community when needed -- ============================================================================ -- VIEWS -- ============================================================================ CREATE OR REPLACE VIEW pending_violations AS SELECT rv.id, rv.community_id, c.name AS community_name, cr.code AS rule_code, cr.title AS rule_title, cr.severity, rv.target_user_id, tu.username AS target_username, rv.reported_by, ru.username AS reporter_username, rv.status, rv.reported_at, rv.report_reason FROM rule_violations rv JOIN communities c ON c.id = rv.community_id JOIN community_rules cr ON cr.id = rv.rule_id JOIN users tu ON tu.id = rv.target_user_id LEFT JOIN users ru ON ru.id = rv.reported_by WHERE rv.status IN ('reported', 'under_review', 'pending_vote') ORDER BY CASE cr.severity WHEN 'critical' THEN 1 WHEN 'major' THEN 2 WHEN 'minor' THEN 3 WHEN 'warning' THEN 4 ELSE 5 END, rv.reported_at; CREATE OR REPLACE VIEW active_sanctions_view AS SELECT s.id, s.community_id, c.name AS community_name, s.target_user_id, u.username AS target_username, s.sanction_type::text, s.severity_level, s.starts_at, s.expires_at, s.status::text, CASE WHEN s.expires_at IS NULL THEN NULL ELSE EXTRACT(EPOCH FROM (s.expires_at - NOW())) / 3600 END AS hours_remaining FROM sanctions s JOIN communities c ON c.id = s.community_id JOIN users u ON u.id = s.target_user_id WHERE s.status = 'active' ORDER BY s.starts_at DESC; -- ============================================================================ -- PLUGIN REGISTRATION -- ============================================================================ INSERT INTO plugins (name, description, version, is_core, is_active, settings_schema) VALUES ( 'self_moderation_rules', 'Community-configurable moderation rules with automatic escalation, voting on sanctions, and transparent governance of governance.', '1.0.0', false, true, jsonb_build_object( 'type', 'object', 'properties', jsonb_build_object( 'default_vote_duration_hours', jsonb_build_object( 'type', 'integer', 'title', 'Default Vote Duration', 'description', 'Default hours for community votes on sanctions', 'default', 48, 'minimum', 12, 'maximum', 168 ), 'auto_expire_sanctions', jsonb_build_object( 'type', 'boolean', 'title', 'Auto-expire Sanctions', 'description', 'Automatically expire sanctions when duration ends', 'default', true ), 'escalation_cooldown_days', jsonb_build_object( 'type', 'integer', 'title', 'Escalation Cooldown', 'description', 'Days of good behavior before escalation level resets', 'default', 90, 'minimum', 30, 'maximum', 365 ), 'require_evidence', jsonb_build_object( 'type', 'boolean', 'title', 'Require Evidence', 'description', 'Require evidence attachment when reporting violations', 'default', false ), 'allow_anonymous_reports', jsonb_build_object( 'type', 'boolean', 'title', 'Allow Anonymous Reports', 'description', 'Allow members to report violations anonymously', 'default', false ) ) ) ) ON CONFLICT (name) DO UPDATE SET version = EXCLUDED.version, description = EXCLUDED.description;