-- ============================================================================ -- CONFLICT RESOLUTION PLUGIN -- Structured mediation, compromise proposals, assisted voting -- Inspired by real-world FLOSS practices -- ============================================================================ -- ============================================================================ -- CONFLICT CASES -- Track conflicts requiring resolution -- ============================================================================ CREATE TYPE conflict_status AS ENUM ( 'reported', -- Initial report 'acknowledged', -- Acknowledged by moderators 'mediation', -- Active mediation in progress 'proposal_phase', -- Compromise proposals being developed 'voting', -- Community voting on resolution 'resolved', -- Successfully resolved 'escalated', -- Escalated to higher authority 'closed' -- Closed without resolution ); CREATE TYPE conflict_type AS ENUM ( 'interpersonal', -- Between community members 'technical', -- Technical disagreement 'governance', -- Governance/policy disagreement 'code_of_conduct', -- CoC violation dispute 'proposal', -- Dispute over a proposal 'moderation', -- Dispute over moderation action 'other' ); CREATE TABLE conflict_cases ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, -- Conflict details title VARCHAR(300) NOT NULL, description TEXT NOT NULL, conflict_type conflict_type NOT NULL, status conflict_status NOT NULL DEFAULT 'reported', -- Parties involved (anonymized IDs for privacy) party_a_id UUID NOT NULL REFERENCES users(id), party_b_id UUID REFERENCES users(id), -- Optional for non-interpersonal affected_parties UUID[] DEFAULT '{}', -- Related content related_proposal_id UUID REFERENCES proposals(id), related_content_ids UUID[] DEFAULT '{}', -- Reporter (can be anonymous) reported_by UUID REFERENCES users(id), reported_anonymously BOOLEAN NOT NULL DEFAULT FALSE, reported_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Severity and urgency severity_level INT NOT NULL DEFAULT 2, -- 1-5 is_urgent BOOLEAN NOT NULL DEFAULT FALSE, -- Resolution tracking resolved_at TIMESTAMPTZ, resolution_type VARCHAR(50), resolution_summary TEXT, -- Metadata tags VARCHAR(50)[] DEFAULT '{}', is_public BOOLEAN NOT NULL DEFAULT FALSE, -- Public visibility created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_conflict_cases_community ON conflict_cases(community_id); CREATE INDEX idx_conflict_cases_status ON conflict_cases(status); CREATE INDEX idx_conflict_cases_parties ON conflict_cases(party_a_id, party_b_id); CREATE INDEX idx_conflict_cases_pending ON conflict_cases(community_id, status) WHERE status NOT IN ('resolved', 'closed'); COMMENT ON TABLE conflict_cases IS 'Tracked conflicts requiring resolution'; -- ============================================================================ -- MEDIATORS -- Assigned mediators for conflict cases -- ============================================================================ CREATE TYPE mediator_role AS ENUM ( 'lead', -- Lead mediator 'assistant', -- Assistant mediator 'observer', -- Observer (learning) 'specialist' -- Subject matter specialist ); CREATE TABLE conflict_mediators ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), conflict_id UUID NOT NULL REFERENCES conflict_cases(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(id), role mediator_role NOT NULL DEFAULT 'assistant', -- Assignment assigned_by UUID REFERENCES users(id), assigned_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Status accepted BOOLEAN, accepted_at TIMESTAMPTZ, recused BOOLEAN NOT NULL DEFAULT FALSE, recusal_reason TEXT, -- Activity last_activity_at TIMESTAMPTZ, notes_count INT NOT NULL DEFAULT 0, UNIQUE(conflict_id, user_id) ); CREATE INDEX idx_conflict_mediators_conflict ON conflict_mediators(conflict_id); CREATE INDEX idx_conflict_mediators_user ON conflict_mediators(user_id); COMMENT ON TABLE conflict_mediators IS 'Mediators assigned to conflict cases'; -- ============================================================================ -- MEDIATION SESSIONS -- Scheduled mediation sessions -- ============================================================================ CREATE TYPE session_status AS ENUM ( 'scheduled', 'in_progress', 'completed', 'cancelled', 'rescheduled' ); CREATE TABLE mediation_sessions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), conflict_id UUID NOT NULL REFERENCES conflict_cases(id) ON DELETE CASCADE, -- Scheduling session_number INT NOT NULL, scheduled_at TIMESTAMPTZ NOT NULL, duration_minutes INT NOT NULL DEFAULT 60, -- Status status session_status NOT NULL DEFAULT 'scheduled', started_at TIMESTAMPTZ, ended_at TIMESTAMPTZ, -- Participants attendees UUID[] NOT NULL DEFAULT '{}', absent_parties UUID[] DEFAULT '{}', -- Session content agenda TEXT, summary TEXT, action_items JSONB DEFAULT '[]', -- Follow-up next_session_needed BOOLEAN, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_mediation_sessions_conflict ON mediation_sessions(conflict_id); CREATE INDEX idx_mediation_sessions_scheduled ON mediation_sessions(scheduled_at); COMMENT ON TABLE mediation_sessions IS 'Scheduled mediation sessions'; -- ============================================================================ -- MEDIATION NOTES -- Private notes from mediators (confidential) -- ============================================================================ CREATE TABLE mediation_notes ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), conflict_id UUID NOT NULL REFERENCES conflict_cases(id) ON DELETE CASCADE, session_id UUID REFERENCES mediation_sessions(id) ON DELETE SET NULL, author_id UUID NOT NULL REFERENCES users(id), -- Note content content TEXT NOT NULL, is_confidential BOOLEAN NOT NULL DEFAULT TRUE, visibility VARCHAR(50) NOT NULL DEFAULT 'mediators', -- mediators, parties, public -- Categorization note_type VARCHAR(50) NOT NULL DEFAULT 'observation', -- observation, concern, progress, action created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_mediation_notes_conflict ON mediation_notes(conflict_id); CREATE INDEX idx_mediation_notes_session ON mediation_notes(session_id); COMMENT ON TABLE mediation_notes IS 'Confidential mediator notes'; -- ============================================================================ -- COMPROMISE PROPOSALS -- Proposed resolutions/compromises -- ============================================================================ CREATE TYPE compromise_status AS ENUM ( 'draft', 'proposed', 'under_review', 'accepted', 'rejected', 'modified', 'implemented' ); CREATE TABLE compromise_proposals ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), conflict_id UUID NOT NULL REFERENCES conflict_cases(id) ON DELETE CASCADE, -- Proposal details title VARCHAR(300) NOT NULL, description TEXT NOT NULL, proposed_actions JSONB NOT NULL DEFAULT '[]', -- Author proposed_by UUID NOT NULL REFERENCES users(id), proposed_by_role VARCHAR(50) NOT NULL, -- mediator, party_a, party_b, community proposed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Status status compromise_status NOT NULL DEFAULT 'draft', -- Acceptance tracking party_a_response VARCHAR(20), -- accept, reject, counter party_a_response_at TIMESTAMPTZ, party_a_feedback TEXT, party_b_response VARCHAR(20), party_b_response_at TIMESTAMPTZ, party_b_feedback TEXT, -- Community vote (if needed) requires_community_vote BOOLEAN NOT NULL DEFAULT FALSE, vote_proposal_id UUID REFERENCES proposals(id), -- Implementation implementation_deadline TIMESTAMPTZ, implemented_at TIMESTAMPTZ, implementation_notes TEXT, version INT NOT NULL DEFAULT 1, parent_proposal_id UUID REFERENCES compromise_proposals(id), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_compromise_proposals_conflict ON compromise_proposals(conflict_id); CREATE INDEX idx_compromise_proposals_status ON compromise_proposals(status); COMMENT ON TABLE compromise_proposals IS 'Proposed compromise resolutions'; -- ============================================================================ -- CONFLICT HISTORY -- Audit trail of all actions taken -- ============================================================================ CREATE TABLE conflict_history ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), conflict_id UUID NOT NULL REFERENCES conflict_cases(id) ON DELETE CASCADE, -- Action details action_type VARCHAR(100) NOT NULL, action_description TEXT, -- Actor actor_id UUID REFERENCES users(id), actor_role VARCHAR(50), -- Changes old_state JSONB, new_state JSONB, -- Visibility is_public BOOLEAN NOT NULL DEFAULT FALSE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_conflict_history_conflict ON conflict_history(conflict_id); CREATE INDEX idx_conflict_history_time ON conflict_history(created_at); COMMENT ON TABLE conflict_history IS 'Audit trail of conflict resolution actions'; -- ============================================================================ -- MEDIATOR POOL -- Community members trained/available for mediation -- ============================================================================ CREATE TABLE mediator_pool ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(id), -- Qualification is_trained BOOLEAN NOT NULL DEFAULT FALSE, trained_at TIMESTAMPTZ, certification_level VARCHAR(50), -- basic, intermediate, advanced specializations VARCHAR(100)[] DEFAULT '{}', -- Availability is_available BOOLEAN NOT NULL DEFAULT TRUE, max_concurrent_cases INT NOT NULL DEFAULT 2, -- Statistics cases_mediated INT NOT NULL DEFAULT 0, successful_resolutions INT NOT NULL DEFAULT 0, avg_resolution_days DECIMAL(5,1), -- Feedback (aggregate, not individual) satisfaction_score DECIMAL(3,2), -- 0-5 created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(community_id, user_id) ); CREATE INDEX idx_mediator_pool_community ON mediator_pool(community_id); CREATE INDEX idx_mediator_pool_available ON mediator_pool(community_id, is_available) WHERE is_available = true; COMMENT ON TABLE mediator_pool IS 'Pool of available mediators'; -- ============================================================================ -- HELPER FUNCTIONS -- ============================================================================ -- Assign mediators to a conflict CREATE OR REPLACE FUNCTION assign_mediators( p_conflict_id UUID, p_assigned_by UUID ) RETURNS INT AS $$ DECLARE v_community_id UUID; v_count INT := 0; v_mediator RECORD; BEGIN -- Get community SELECT community_id INTO v_community_id FROM conflict_cases WHERE id = p_conflict_id; -- Find available mediators (not party to conflict) FOR v_mediator IN SELECT mp.user_id FROM mediator_pool mp WHERE mp.community_id = v_community_id AND mp.is_available = true AND mp.user_id NOT IN ( SELECT party_a_id FROM conflict_cases WHERE id = p_conflict_id UNION SELECT party_b_id FROM conflict_cases WHERE id = p_conflict_id AND party_b_id IS NOT NULL ) AND (SELECT COUNT(*) FROM conflict_mediators cm JOIN conflict_cases cc ON cc.id = cm.conflict_id WHERE cm.user_id = mp.user_id AND cc.status NOT IN ('resolved', 'closed') ) < mp.max_concurrent_cases ORDER BY mp.cases_mediated ASC, RANDOM() LIMIT 2 LOOP INSERT INTO conflict_mediators (conflict_id, user_id, role, assigned_by) VALUES (p_conflict_id, v_mediator.user_id, CASE WHEN v_count = 0 THEN 'lead' ELSE 'assistant' END::mediator_role, p_assigned_by) ON CONFLICT DO NOTHING; v_count := v_count + 1; END LOOP; -- Update conflict status if mediators assigned IF v_count > 0 THEN UPDATE conflict_cases SET status = 'acknowledged', updated_at = NOW() WHERE id = p_conflict_id AND status = 'reported'; -- Log action INSERT INTO conflict_history (conflict_id, action_type, action_description, actor_id) VALUES (p_conflict_id, 'mediators_assigned', v_count || ' mediator(s) assigned', p_assigned_by); END IF; RETURN v_count; END; $$ LANGUAGE plpgsql; -- Transition conflict status CREATE OR REPLACE FUNCTION transition_conflict_status( p_conflict_id UUID, p_new_status conflict_status, p_actor_id UUID, p_notes TEXT DEFAULT NULL ) RETURNS BOOLEAN AS $$ DECLARE v_old_status conflict_status; BEGIN SELECT status INTO v_old_status FROM conflict_cases WHERE id = p_conflict_id; -- Update status UPDATE conflict_cases SET status = p_new_status, updated_at = NOW(), resolved_at = CASE WHEN p_new_status IN ('resolved', 'closed') THEN NOW() ELSE resolved_at END WHERE id = p_conflict_id; -- Log transition INSERT INTO conflict_history (conflict_id, action_type, action_description, actor_id, old_state, new_state) VALUES (p_conflict_id, 'status_change', p_notes, p_actor_id, jsonb_build_object('status', v_old_status), jsonb_build_object('status', p_new_status)); RETURN TRUE; END; $$ LANGUAGE plpgsql; -- Calculate conflict resolution statistics CREATE OR REPLACE FUNCTION get_conflict_statistics(p_community_id UUID) RETURNS TABLE ( total_conflicts BIGINT, resolved_conflicts BIGINT, avg_resolution_days DECIMAL, mediation_success_rate DECIMAL, active_conflicts BIGINT ) AS $$ BEGIN RETURN QUERY SELECT COUNT(*)::BIGINT, COUNT(*) FILTER (WHERE status = 'resolved')::BIGINT, AVG(EXTRACT(EPOCH FROM (resolved_at - created_at)) / 86400)::DECIMAL(10,2), (COUNT(*) FILTER (WHERE status = 'resolved')::DECIMAL / NULLIF(COUNT(*) FILTER (WHERE status IN ('resolved', 'closed')), 0))::DECIMAL(5,4), COUNT(*) FILTER (WHERE status NOT IN ('resolved', 'closed'))::BIGINT FROM conflict_cases WHERE community_id = p_community_id; END; $$ LANGUAGE plpgsql; -- ============================================================================ -- VIEWS -- ============================================================================ CREATE OR REPLACE VIEW active_conflicts AS SELECT cc.id, cc.community_id, c.name AS community_name, cc.title, cc.conflict_type::text, cc.status::text, cc.severity_level, cc.is_urgent, cc.reported_at, ARRAY_AGG(DISTINCT u.username) FILTER (WHERE cm.role = 'lead') AS lead_mediators, COUNT(DISTINCT cp.id) AS compromise_proposals_count, COUNT(DISTINCT ms.id) AS sessions_count FROM conflict_cases cc JOIN communities c ON c.id = cc.community_id LEFT JOIN conflict_mediators cm ON cm.conflict_id = cc.id LEFT JOIN users u ON u.id = cm.user_id LEFT JOIN compromise_proposals cp ON cp.conflict_id = cc.id LEFT JOIN mediation_sessions ms ON ms.conflict_id = cc.id WHERE cc.status NOT IN ('resolved', 'closed') GROUP BY cc.id, cc.community_id, c.name, cc.title, cc.conflict_type, cc.status, cc.severity_level, cc.is_urgent, cc.reported_at ORDER BY cc.is_urgent DESC, cc.severity_level DESC, cc.reported_at; CREATE OR REPLACE VIEW mediator_workload AS SELECT mp.user_id, u.username, mp.community_id, mp.certification_level, mp.is_available, mp.max_concurrent_cases, COUNT(cm.id) FILTER (WHERE cc.status NOT IN ('resolved', 'closed')) AS active_cases, mp.cases_mediated AS total_cases, mp.successful_resolutions, mp.satisfaction_score FROM mediator_pool mp JOIN users u ON u.id = mp.user_id LEFT JOIN conflict_mediators cm ON cm.user_id = mp.user_id LEFT JOIN conflict_cases cc ON cc.id = cm.conflict_id GROUP BY mp.user_id, u.username, mp.community_id, mp.certification_level, mp.is_available, mp.max_concurrent_cases, mp.cases_mediated, mp.successful_resolutions, mp.satisfaction_score; -- ============================================================================ -- PLUGIN REGISTRATION -- ============================================================================ INSERT INTO plugins (name, description, version, is_core, is_active, settings_schema) VALUES ( 'conflict_resolution', 'Structured conflict resolution with mediation sessions, compromise proposals, and assisted voting. Inspired by real-world FLOSS community practices.', '1.0.0', false, true, jsonb_build_object( 'type', 'object', 'properties', jsonb_build_object( 'auto_assign_mediators', jsonb_build_object( 'type', 'boolean', 'title', 'Auto-assign Mediators', 'description', 'Automatically assign available mediators to new conflicts', 'default', true ), 'min_mediators', jsonb_build_object( 'type', 'integer', 'title', 'Minimum Mediators', 'description', 'Minimum number of mediators per conflict', 'default', 1, 'minimum', 1, 'maximum', 5 ), 'max_resolution_days', jsonb_build_object( 'type', 'integer', 'title', 'Max Resolution Days', 'description', 'Target days for conflict resolution', 'default', 30, 'minimum', 7 ), 'require_compromise_vote', jsonb_build_object( 'type', 'boolean', 'title', 'Require Community Vote', 'description', 'Require community vote on compromise proposals', 'default', false ), 'anonymous_reporting', jsonb_build_object( 'type', 'boolean', 'title', 'Allow Anonymous Reporting', 'description', 'Allow conflicts to be reported anonymously', 'default', true ) ) ) ) ON CONFLICT (name) DO UPDATE SET version = EXCLUDED.version, description = EXCLUDED.description;