-- ============================================================================ -- STRUCTURED DELIBERATION PLUGIN -- Pro/con arguments, collaborative summaries, noise reduction -- ============================================================================ -- Enable ltree extension for hierarchical threading CREATE EXTENSION IF NOT EXISTS ltree; -- ============================================================================ -- ARGUMENT THREADS -- Structured pro/con arguments linked to proposals -- ============================================================================ CREATE TYPE argument_stance AS ENUM ('pro', 'con', 'neutral', 'question', 'clarification'); CREATE TABLE deliberation_arguments ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE, parent_id UUID REFERENCES deliberation_arguments(id) ON DELETE CASCADE, -- Argument content stance argument_stance NOT NULL, title VARCHAR(300) NOT NULL, content TEXT NOT NULL, -- Author author_id UUID NOT NULL REFERENCES users(id), -- Engagement metrics upvotes INT NOT NULL DEFAULT 0, downvotes INT NOT NULL DEFAULT 0, reply_count INT NOT NULL DEFAULT 0, -- Quality indicators is_substantive BOOLEAN NOT NULL DEFAULT TRUE, is_featured BOOLEAN NOT NULL DEFAULT FALSE, quality_score DECIMAL(5,2) DEFAULT 0, -- Moderation is_hidden BOOLEAN NOT NULL DEFAULT FALSE, hidden_reason TEXT, -- Threading depth INT NOT NULL DEFAULT 0, thread_path LTREE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_deliberation_arguments_proposal ON deliberation_arguments(proposal_id); CREATE INDEX idx_deliberation_arguments_parent ON deliberation_arguments(parent_id); CREATE INDEX idx_deliberation_arguments_stance ON deliberation_arguments(proposal_id, stance); CREATE INDEX idx_deliberation_arguments_featured ON deliberation_arguments(proposal_id, is_featured) WHERE is_featured = true; CREATE INDEX idx_deliberation_arguments_quality ON deliberation_arguments(proposal_id, quality_score DESC); COMMENT ON TABLE deliberation_arguments IS 'Structured pro/con arguments for proposals'; -- ============================================================================ -- ARGUMENT VOTES -- Community voting on argument quality/relevance -- ============================================================================ CREATE TABLE argument_votes ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), argument_id UUID NOT NULL REFERENCES deliberation_arguments(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(id), vote_type VARCHAR(20) NOT NULL, -- upvote, downvote created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(argument_id, user_id) ); CREATE INDEX idx_argument_votes_argument ON argument_votes(argument_id); -- ============================================================================ -- COLLABORATIVE SUMMARIES -- Community-maintained summaries of deliberation -- ============================================================================ CREATE TYPE summary_type AS ENUM ( 'executive', -- Brief executive summary 'pro_arguments', -- Summary of pro arguments 'con_arguments', -- Summary of con arguments 'consensus', -- Areas of consensus 'contention', -- Points of contention 'questions', -- Open questions 'full' -- Full deliberation summary ); CREATE TABLE deliberation_summaries ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE, summary_type summary_type NOT NULL, -- Content content TEXT NOT NULL, key_points JSONB DEFAULT '[]', -- Versioning version INT NOT NULL DEFAULT 1, -- Author/Editor last_editor_id UUID NOT NULL REFERENCES users(id), -- Approval is_approved BOOLEAN NOT NULL DEFAULT FALSE, approved_by UUID REFERENCES users(id), approved_at TIMESTAMPTZ, -- Metrics edit_count INT NOT NULL DEFAULT 1, view_count INT NOT NULL DEFAULT 0, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(proposal_id, summary_type) ); CREATE INDEX idx_deliberation_summaries_proposal ON deliberation_summaries(proposal_id); COMMENT ON TABLE deliberation_summaries IS 'Collaborative summaries of deliberation'; -- ============================================================================ -- SUMMARY EDIT HISTORY -- Track all edits to summaries -- ============================================================================ CREATE TABLE summary_edit_history ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), summary_id UUID NOT NULL REFERENCES deliberation_summaries(id) ON DELETE CASCADE, version INT NOT NULL, content TEXT NOT NULL, key_points JSONB, editor_id UUID NOT NULL REFERENCES users(id), edit_comment TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_summary_edit_history_summary ON summary_edit_history(summary_id); -- ============================================================================ -- READING REQUIREMENTS -- Track if users have read required content before participating -- ============================================================================ CREATE TABLE deliberation_reading_log ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(id), -- What was read read_proposal BOOLEAN NOT NULL DEFAULT FALSE, read_summaries BOOLEAN NOT NULL DEFAULT FALSE, read_top_arguments BOOLEAN NOT NULL DEFAULT FALSE, -- Timing first_read_at TIMESTAMPTZ, reading_time_seconds INT NOT NULL DEFAULT 0, -- Can participate can_comment BOOLEAN GENERATED ALWAYS AS (read_proposal) STORED, can_vote BOOLEAN GENERATED ALWAYS AS (read_proposal AND read_summaries) STORED, updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(proposal_id, user_id) ); CREATE INDEX idx_reading_log_proposal ON deliberation_reading_log(proposal_id); CREATE INDEX idx_reading_log_user ON deliberation_reading_log(user_id); COMMENT ON TABLE deliberation_reading_log IS 'Track reading before participation'; -- ============================================================================ -- DISCUSSION QUALITY METRICS -- Track deliberation quality over time -- ============================================================================ CREATE TABLE deliberation_metrics ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE, calculated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Argument counts total_arguments INT NOT NULL DEFAULT 0, pro_arguments INT NOT NULL DEFAULT 0, con_arguments INT NOT NULL DEFAULT 0, neutral_arguments INT NOT NULL DEFAULT 0, -- Participation unique_participants INT NOT NULL DEFAULT 0, avg_argument_length INT, -- Quality indicators substantive_ratio DECIMAL(5,4), -- Ratio of substantive arguments engagement_score DECIMAL(5,2), balance_score DECIMAL(5,4), -- How balanced pro/con -- Reading compliance readers_before_posting DECIMAL(5,4), UNIQUE(proposal_id, calculated_at) ); CREATE INDEX idx_deliberation_metrics_proposal ON deliberation_metrics(proposal_id); -- ============================================================================ -- FACILITATION PROMPTS -- AI/moderator prompts to improve deliberation -- ============================================================================ CREATE TABLE facilitation_prompts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE, -- Prompt content prompt_type VARCHAR(50) NOT NULL, -- balance_needed, clarification_needed, summary_outdated message TEXT NOT NULL, -- Targeting target_stance argument_stance, -- Status is_active BOOLEAN NOT NULL DEFAULT TRUE, addressed_at TIMESTAMPTZ, addressed_by UUID REFERENCES users(id), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_facilitation_prompts_proposal ON facilitation_prompts(proposal_id); -- ============================================================================ -- HELPER FUNCTIONS -- ============================================================================ -- Add an argument and update counts CREATE OR REPLACE FUNCTION add_deliberation_argument( p_proposal_id UUID, p_parent_id UUID, p_stance argument_stance, p_title VARCHAR(300), p_content TEXT, p_author_id UUID ) RETURNS UUID AS $$ DECLARE v_argument_id UUID; v_depth INT := 0; v_parent_path LTREE; BEGIN -- Calculate depth and path IF p_parent_id IS NOT NULL THEN SELECT depth + 1, thread_path INTO v_depth, v_parent_path FROM deliberation_arguments WHERE id = p_parent_id; END IF; -- Insert argument INSERT INTO deliberation_arguments ( proposal_id, parent_id, stance, title, content, author_id, depth ) VALUES ( p_proposal_id, p_parent_id, p_stance, p_title, p_content, p_author_id, v_depth ) RETURNING id INTO v_argument_id; -- Update thread path UPDATE deliberation_arguments SET thread_path = COALESCE(v_parent_path || v_argument_id::text, v_argument_id::text::ltree) WHERE id = v_argument_id; -- Update parent reply count IF p_parent_id IS NOT NULL THEN UPDATE deliberation_arguments SET reply_count = reply_count + 1, updated_at = NOW() WHERE id = p_parent_id; END IF; RETURN v_argument_id; END; $$ LANGUAGE plpgsql; -- Vote on an argument CREATE OR REPLACE FUNCTION vote_on_argument( p_argument_id UUID, p_user_id UUID, p_vote_type VARCHAR(20) ) RETURNS VOID AS $$ DECLARE v_old_vote VARCHAR(20); BEGIN -- Get existing vote SELECT vote_type INTO v_old_vote FROM argument_votes WHERE argument_id = p_argument_id AND user_id = p_user_id; -- Remove old vote effect IF v_old_vote IS NOT NULL THEN UPDATE deliberation_arguments SET upvotes = upvotes - CASE WHEN v_old_vote = 'upvote' THEN 1 ELSE 0 END, downvotes = downvotes - CASE WHEN v_old_vote = 'downvote' THEN 1 ELSE 0 END WHERE id = p_argument_id; END IF; -- Insert/update vote INSERT INTO argument_votes (argument_id, user_id, vote_type) VALUES (p_argument_id, p_user_id, p_vote_type) ON CONFLICT (argument_id, user_id) DO UPDATE SET vote_type = p_vote_type, created_at = NOW(); -- Apply new vote UPDATE deliberation_arguments SET upvotes = upvotes + CASE WHEN p_vote_type = 'upvote' THEN 1 ELSE 0 END, downvotes = downvotes + CASE WHEN p_vote_type = 'downvote' THEN 1 ELSE 0 END, quality_score = (upvotes + CASE WHEN p_vote_type = 'upvote' THEN 1 ELSE 0 END - downvotes - CASE WHEN p_vote_type = 'downvote' THEN 1 ELSE 0 END)::DECIMAL / GREATEST(upvotes + downvotes + 1, 1) WHERE id = p_argument_id; END; $$ LANGUAGE plpgsql; -- Calculate deliberation metrics CREATE OR REPLACE FUNCTION calculate_deliberation_metrics(p_proposal_id UUID) RETURNS UUID AS $$ DECLARE v_metric_id UUID; BEGIN INSERT INTO deliberation_metrics ( proposal_id, total_arguments, pro_arguments, con_arguments, neutral_arguments, unique_participants, avg_argument_length, substantive_ratio, balance_score ) SELECT p_proposal_id, COUNT(*), COUNT(*) FILTER (WHERE stance = 'pro'), COUNT(*) FILTER (WHERE stance = 'con'), COUNT(*) FILTER (WHERE stance = 'neutral'), COUNT(DISTINCT author_id), AVG(LENGTH(content))::INT, COUNT(*) FILTER (WHERE is_substantive)::DECIMAL / NULLIF(COUNT(*), 0), 1 - ABS( COUNT(*) FILTER (WHERE stance = 'pro')::DECIMAL / NULLIF(COUNT(*) FILTER (WHERE stance IN ('pro', 'con')), 0) - 0.5 ) * 2 FROM deliberation_arguments WHERE proposal_id = p_proposal_id AND NOT is_hidden RETURNING id INTO v_metric_id; RETURN v_metric_id; END; $$ LANGUAGE plpgsql; -- ============================================================================ -- VIEWS -- ============================================================================ CREATE OR REPLACE VIEW proposal_deliberation_summary AS SELECT p.id AS proposal_id, p.title AS proposal_title, COUNT(da.id) AS total_arguments, COUNT(da.id) FILTER (WHERE da.stance = 'pro') AS pro_count, COUNT(da.id) FILTER (WHERE da.stance = 'con') AS con_count, COUNT(DISTINCT da.author_id) AS participants, COUNT(ds.id) AS summaries_count, BOOL_OR(ds.is_approved) AS has_approved_summary, MAX(da.quality_score) AS top_argument_score FROM proposals p LEFT JOIN deliberation_arguments da ON da.proposal_id = p.id AND NOT da.is_hidden LEFT JOIN deliberation_summaries ds ON ds.proposal_id = p.id GROUP BY p.id, p.title; CREATE OR REPLACE VIEW top_arguments AS SELECT da.id, da.proposal_id, da.stance::text, da.title, da.content, u.username AS author_username, da.upvotes, da.downvotes, da.quality_score, da.is_featured, da.reply_count, da.created_at FROM deliberation_arguments da JOIN users u ON u.id = da.author_id WHERE NOT da.is_hidden AND da.parent_id IS NULL ORDER BY da.proposal_id, da.quality_score DESC; -- ============================================================================ -- PLUGIN REGISTRATION -- ============================================================================ INSERT INTO plugins (name, description, version, is_core, is_active, settings_schema) VALUES ( 'structured_deliberation', 'Structured deliberation with pro/con arguments, collaborative summaries, and quality metrics. Reduces noise and promotes thoughtful discussion.', '1.0.0', false, true, jsonb_build_object( 'type', 'object', 'properties', jsonb_build_object( 'require_reading', jsonb_build_object( 'type', 'boolean', 'title', 'Require Reading', 'description', 'Require users to read proposal before commenting', 'default', true ), 'min_reading_time_seconds', jsonb_build_object( 'type', 'integer', 'title', 'Minimum Reading Time', 'description', 'Minimum seconds spent reading before can participate', 'default', 30, 'minimum', 0 ), 'enable_summaries', jsonb_build_object( 'type', 'boolean', 'title', 'Enable Summaries', 'description', 'Enable collaborative summary creation', 'default', true ), 'summary_approval_required', jsonb_build_object( 'type', 'boolean', 'title', 'Summary Approval Required', 'description', 'Require moderator approval for summaries', 'default', false ), 'show_balance_prompts', jsonb_build_object( 'type', 'boolean', 'title', 'Show Balance Prompts', 'description', 'Show prompts when deliberation is unbalanced', 'default', true ), 'featured_argument_threshold', jsonb_build_object( 'type', 'integer', 'title', 'Featured Threshold', 'description', 'Minimum upvotes for auto-featuring', 'default', 10, 'minimum', 1 ) ) ) ) ON CONFLICT (name) DO UPDATE SET version = EXCLUDED.version, description = EXCLUDED.description;