-- ============================================================================ -- GOVERNANCE ANALYTICS PLUGIN -- Participation metrics, delegation distribution, decision load analytics -- No individual ranking - focuses on aggregate health metrics -- ============================================================================ -- ============================================================================ -- PARTICIPATION SNAPSHOTS -- Periodic snapshots of participation metrics -- ============================================================================ CREATE TABLE participation_snapshots ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, snapshot_date DATE NOT NULL, snapshot_type VARCHAR(50) NOT NULL DEFAULT 'daily', -- daily, weekly, monthly -- Member counts total_members INT NOT NULL DEFAULT 0, active_members INT NOT NULL DEFAULT 0, -- Active in period new_members INT NOT NULL DEFAULT 0, churned_members INT NOT NULL DEFAULT 0, -- Proposal metrics proposals_created INT NOT NULL DEFAULT 0, proposals_passed INT NOT NULL DEFAULT 0, proposals_rejected INT NOT NULL DEFAULT 0, proposals_active INT NOT NULL DEFAULT 0, -- Voting metrics votes_cast INT NOT NULL DEFAULT 0, unique_voters INT NOT NULL DEFAULT 0, avg_votes_per_proposal DECIMAL(10,2), voter_turnout_rate DECIMAL(5,4), -- percentage -- Discussion metrics comments_created INT NOT NULL DEFAULT 0, unique_commenters INT NOT NULL DEFAULT 0, avg_comments_per_proposal DECIMAL(10,2), -- Delegation metrics active_delegations INT NOT NULL DEFAULT 0, delegation_depth_avg DECIMAL(5,2), delegation_concentration DECIMAL(5,4), -- Gini-like measure -- Engagement score (aggregate, not individual) engagement_score DECIMAL(5,2), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(community_id, snapshot_date, snapshot_type) ); CREATE INDEX idx_participation_snapshots_community ON participation_snapshots(community_id); CREATE INDEX idx_participation_snapshots_date ON participation_snapshots(snapshot_date); CREATE INDEX idx_participation_snapshots_lookup ON participation_snapshots(community_id, snapshot_date DESC); COMMENT ON TABLE participation_snapshots IS 'Periodic participation metrics snapshots'; -- ============================================================================ -- DELEGATION ANALYTICS -- Aggregate delegation network analysis (no individual tracking) -- ============================================================================ CREATE TABLE delegation_analytics ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, topic_id UUID, -- Optional topic filtering snapshot_date DATE NOT NULL, -- Network metrics total_delegations INT NOT NULL DEFAULT 0, unique_delegators INT NOT NULL DEFAULT 0, unique_delegates INT NOT NULL DEFAULT 0, -- Chain analysis max_chain_depth INT NOT NULL DEFAULT 0, avg_chain_depth DECIMAL(5,2), delegation_cycles_detected INT NOT NULL DEFAULT 0, -- Concentration metrics (no individual data) top_10_delegate_share DECIMAL(5,4), -- Share of votes held by top 10 delegates herfindahl_index DECIMAL(7,6), -- Market concentration measure effective_delegates INT, -- Number of delegates holding 50% of delegated power -- Activity delegations_created INT NOT NULL DEFAULT 0, delegations_revoked INT NOT NULL DEFAULT 0, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(community_id, topic_id, snapshot_date) ); CREATE INDEX idx_delegation_analytics_community ON delegation_analytics(community_id); CREATE INDEX idx_delegation_analytics_topic ON delegation_analytics(topic_id); COMMENT ON TABLE delegation_analytics IS 'Aggregate delegation network metrics'; -- ============================================================================ -- DECISION LOAD METRICS -- Track governance workload and throughput -- ============================================================================ CREATE TABLE decision_load_metrics ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, period_start DATE NOT NULL, period_end DATE NOT NULL, -- Workload proposals_in_pipeline INT NOT NULL DEFAULT 0, proposals_needing_review INT NOT NULL DEFAULT 0, proposals_in_voting INT NOT NULL DEFAULT 0, -- Throughput decisions_made INT NOT NULL DEFAULT 0, avg_decision_time_hours DECIMAL(10,2), median_decision_time_hours DECIMAL(10,2), -- Quality indicators proposals_requiring_revision INT NOT NULL DEFAULT 0, revision_rate DECIMAL(5,4), quorum_achievement_rate DECIMAL(5,4), -- Bottlenecks stalled_proposals INT NOT NULL DEFAULT 0, bottleneck_phase VARCHAR(50), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(community_id, period_start, period_end) ); CREATE INDEX idx_decision_load_community ON decision_load_metrics(community_id); COMMENT ON TABLE decision_load_metrics IS 'Governance workload and throughput metrics'; -- ============================================================================ -- VOTING METHOD ANALYTICS -- Compare effectiveness of different voting methods -- ============================================================================ CREATE TABLE voting_method_analytics ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, voting_method VARCHAR(50) NOT NULL, period_start DATE NOT NULL, period_end DATE NOT NULL, -- Usage proposals_using_method INT NOT NULL DEFAULT 0, total_votes_cast INT NOT NULL DEFAULT 0, -- Participation avg_turnout DECIMAL(5,4), avg_time_to_decide_hours DECIMAL(10,2), -- Outcomes decisive_results INT NOT NULL DEFAULT 0, -- Clear winner close_results INT NOT NULL DEFAULT 0, -- Narrow margins tie_results INT NOT NULL DEFAULT 0, -- Satisfaction proxy (based on post-vote engagement) post_decision_engagement_rate DECIMAL(5,4), appeal_rate DECIMAL(5,4), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(community_id, voting_method, period_start, period_end) ); CREATE INDEX idx_voting_method_analytics_community ON voting_method_analytics(community_id); COMMENT ON TABLE voting_method_analytics IS 'Voting method effectiveness comparison'; -- ============================================================================ -- HEALTH INDICATORS -- Overall governance health dashboard data -- ============================================================================ CREATE TABLE governance_health_indicators ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, calculated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Participation health (0-100) participation_score DECIMAL(5,2), participation_trend VARCHAR(20), -- improving, stable, declining -- Inclusion health inclusion_score DECIMAL(5,2), new_voice_ratio DECIMAL(5,4), -- New participants in decisions -- Efficiency health efficiency_score DECIMAL(5,2), decision_velocity DECIMAL(10,2), -- Decisions per week -- Legitimacy health legitimacy_score DECIMAL(5,2), avg_quorum_margin DECIMAL(5,4), -- How much above quorum -- Delegation health delegation_health_score DECIMAL(5,2), power_concentration_risk VARCHAR(20), -- low, medium, high -- Overall overall_health_score DECIMAL(5,2), recommendations JSONB, UNIQUE(community_id, calculated_at) ); CREATE INDEX idx_health_indicators_community ON governance_health_indicators(community_id); CREATE INDEX idx_health_indicators_time ON governance_health_indicators(community_id, calculated_at DESC); COMMENT ON TABLE governance_health_indicators IS 'Composite governance health metrics'; -- ============================================================================ -- HELPER FUNCTIONS -- ============================================================================ -- Calculate participation snapshot for a community CREATE OR REPLACE FUNCTION calculate_participation_snapshot( p_community_id UUID, p_date DATE DEFAULT CURRENT_DATE ) RETURNS UUID AS $$ DECLARE v_snapshot_id UUID; v_total_members INT; v_active_members INT; v_proposals_created INT; v_votes_cast INT; v_unique_voters INT; v_active_delegations INT; BEGIN -- Get member counts SELECT COUNT(*) INTO v_total_members FROM community_members WHERE community_id = p_community_id; -- Active members (any activity in last 30 days) SELECT COUNT(DISTINCT user_id) INTO v_active_members FROM ( SELECT author_id AS user_id FROM proposals WHERE community_id = p_community_id AND created_at > p_date - INTERVAL '30 days' UNION SELECT user_id FROM votes v JOIN proposals p ON p.id = v.proposal_id WHERE p.community_id = p_community_id AND v.created_at > p_date - INTERVAL '30 days' UNION SELECT author_id FROM comments c JOIN proposals p ON p.id = c.proposal_id WHERE p.community_id = p_community_id AND c.created_at > p_date - INTERVAL '30 days' ) activity; -- Proposals in period SELECT COUNT(*) INTO v_proposals_created FROM proposals WHERE community_id = p_community_id AND created_at::DATE = p_date; -- Votes in period SELECT COUNT(*), COUNT(DISTINCT user_id) INTO v_votes_cast, v_unique_voters FROM votes v JOIN proposals p ON p.id = v.proposal_id WHERE p.community_id = p_community_id AND v.created_at::DATE = p_date; -- Active delegations SELECT COUNT(*) INTO v_active_delegations FROM delegations WHERE community_id = p_community_id AND (expires_at IS NULL OR expires_at > NOW()); -- Insert snapshot INSERT INTO participation_snapshots ( community_id, snapshot_date, snapshot_type, total_members, active_members, proposals_created, votes_cast, unique_voters, active_delegations, voter_turnout_rate, engagement_score ) VALUES ( p_community_id, p_date, 'daily', v_total_members, v_active_members, v_proposals_created, v_votes_cast, v_unique_voters, v_active_delegations, CASE WHEN v_total_members > 0 THEN v_unique_voters::DECIMAL / v_total_members ELSE 0 END, CASE WHEN v_total_members > 0 THEN v_active_members::DECIMAL / v_total_members * 100 ELSE 0 END ) ON CONFLICT (community_id, snapshot_date, snapshot_type) DO UPDATE SET total_members = EXCLUDED.total_members, active_members = EXCLUDED.active_members, proposals_created = EXCLUDED.proposals_created, votes_cast = EXCLUDED.votes_cast, unique_voters = EXCLUDED.unique_voters, active_delegations = EXCLUDED.active_delegations, voter_turnout_rate = EXCLUDED.voter_turnout_rate, engagement_score = EXCLUDED.engagement_score RETURNING id INTO v_snapshot_id; RETURN v_snapshot_id; END; $$ LANGUAGE plpgsql; -- Calculate delegation concentration (Herfindahl Index) CREATE OR REPLACE FUNCTION calculate_delegation_concentration( p_community_id UUID ) RETURNS DECIMAL AS $$ DECLARE v_hhi DECIMAL; v_total_delegated DECIMAL; BEGIN -- Get total delegated voting power SELECT COALESCE(SUM(voting_power), 0) INTO v_total_delegated FROM delegations WHERE community_id = p_community_id AND (expires_at IS NULL OR expires_at > NOW()); IF v_total_delegated = 0 THEN RETURN 0; END IF; -- Calculate HHI (sum of squared market shares) SELECT COALESCE(SUM(POWER(delegate_share, 2)), 0) INTO v_hhi FROM ( SELECT delegate_id, SUM(voting_power)::DECIMAL / v_total_delegated AS delegate_share FROM delegations WHERE community_id = p_community_id AND (expires_at IS NULL OR expires_at > NOW()) GROUP BY delegate_id ) shares; RETURN v_hhi; END; $$ LANGUAGE plpgsql; -- Calculate governance health score CREATE OR REPLACE FUNCTION calculate_governance_health( p_community_id UUID ) RETURNS UUID AS $$ DECLARE v_health_id UUID; v_participation_score DECIMAL; v_efficiency_score DECIMAL; v_delegation_score DECIMAL; v_overall_score DECIMAL; v_hhi DECIMAL; v_power_risk VARCHAR(20); BEGIN -- Participation score (based on recent activity) SELECT COALESCE(AVG(engagement_score), 50) INTO v_participation_score FROM participation_snapshots WHERE community_id = p_community_id AND snapshot_date > CURRENT_DATE - INTERVAL '30 days'; -- Efficiency score (based on decision throughput) SELECT COALESCE( 100 - (COALESCE(AVG(avg_decision_time_hours), 168) / 168 * 50), -- Penalize slow decisions 50 ) INTO v_efficiency_score FROM decision_load_metrics WHERE community_id = p_community_id AND period_end > CURRENT_DATE - INTERVAL '30 days'; -- Delegation health v_hhi := calculate_delegation_concentration(p_community_id); v_delegation_score := 100 - (v_hhi * 100); -- Lower HHI = better -- Determine power concentration risk v_power_risk := CASE WHEN v_hhi > 0.25 THEN 'high' WHEN v_hhi > 0.15 THEN 'medium' ELSE 'low' END; -- Overall score (weighted average) v_overall_score := (v_participation_score * 0.4 + v_efficiency_score * 0.3 + v_delegation_score * 0.3); -- Insert health record INSERT INTO governance_health_indicators ( community_id, participation_score, participation_trend, efficiency_score, delegation_health_score, power_concentration_risk, overall_health_score, recommendations ) VALUES ( p_community_id, v_participation_score, 'stable', -- Would need trend calculation v_efficiency_score, v_delegation_score, v_power_risk, v_overall_score, jsonb_build_array( CASE WHEN v_participation_score < 50 THEN 'Consider outreach to increase participation' END, CASE WHEN v_efficiency_score < 50 THEN 'Review workflow to reduce decision time' END, CASE WHEN v_power_risk = 'high' THEN 'High delegation concentration - encourage diverse delegation' END ) ) RETURNING id INTO v_health_id; RETURN v_health_id; END; $$ LANGUAGE plpgsql; -- ============================================================================ -- VIEWS -- ============================================================================ CREATE OR REPLACE VIEW community_health_dashboard AS SELECT c.id AS community_id, c.name AS community_name, ghi.overall_health_score, ghi.participation_score, ghi.efficiency_score, ghi.delegation_health_score, ghi.power_concentration_risk, ghi.calculated_at AS last_calculated, ps.total_members, ps.active_members, ps.voter_turnout_rate FROM communities c LEFT JOIN LATERAL ( SELECT * FROM governance_health_indicators WHERE community_id = c.id ORDER BY calculated_at DESC LIMIT 1 ) ghi ON true LEFT JOIN LATERAL ( SELECT * FROM participation_snapshots WHERE community_id = c.id ORDER BY snapshot_date DESC LIMIT 1 ) ps ON true; CREATE OR REPLACE VIEW participation_trends AS SELECT community_id, snapshot_date, total_members, active_members, ROUND(active_members::DECIMAL / NULLIF(total_members, 0) * 100, 2) AS active_rate, votes_cast, unique_voters, voter_turnout_rate, engagement_score, LAG(engagement_score) OVER (PARTITION BY community_id ORDER BY snapshot_date) AS prev_engagement, engagement_score - LAG(engagement_score) OVER (PARTITION BY community_id ORDER BY snapshot_date) AS engagement_change FROM participation_snapshots WHERE snapshot_type = 'daily' ORDER BY community_id, snapshot_date DESC; -- ============================================================================ -- PLUGIN REGISTRATION -- ============================================================================ INSERT INTO plugins (name, description, version, is_core, is_active, settings_schema) VALUES ( 'governance_analytics', 'Aggregate governance analytics including participation metrics, delegation distribution, and decision load tracking. No individual ranking - focuses on community health.', '1.0.0', false, true, jsonb_build_object( 'type', 'object', 'properties', jsonb_build_object( 'snapshot_frequency', jsonb_build_object( 'type', 'string', 'title', 'Snapshot Frequency', 'description', 'How often to calculate participation snapshots', 'enum', ARRAY['hourly', 'daily', 'weekly'], 'default', 'daily' ), 'health_check_frequency', jsonb_build_object( 'type', 'string', 'title', 'Health Check Frequency', 'description', 'How often to calculate governance health', 'enum', ARRAY['daily', 'weekly'], 'default', 'weekly' ), 'retention_days', jsonb_build_object( 'type', 'integer', 'title', 'Data Retention', 'description', 'Days to retain detailed analytics data', 'default', 365, 'minimum', 30 ), 'public_dashboard', jsonb_build_object( 'type', 'boolean', 'title', 'Public Dashboard', 'description', 'Make analytics dashboard visible to all members', 'default', true ) ) ) ) ON CONFLICT (name) DO UPDATE SET version = EXCLUDED.version, description = EXCLUDED.description;