-- Vote Reproducibility: Bind votes to plugin versions for audit integrity -- This ensures votes can always be re-verified using the exact logic that was active -- Add plugin version tracking to proposals ALTER TABLE proposals ADD COLUMN IF NOT EXISTS voting_plugin_version VARCHAR(20); ALTER TABLE proposals ADD COLUMN IF NOT EXISTS voting_plugin_hash VARCHAR(64); -- Archive of plugin WASM binaries for reproducibility CREATE TABLE IF NOT EXISTS plugin_wasm_archive ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), plugin_name VARCHAR(100) NOT NULL, version VARCHAR(20) NOT NULL, wasm_binary BYTEA, -- Actual WASM code (nullable for built-in methods) wasm_hash VARCHAR(64) NOT NULL, config_schema JSONB, -- Schema at time of archive algorithm_description TEXT, -- Human-readable description of the algorithm archived_at TIMESTAMPTZ DEFAULT NOW(), archived_by UUID REFERENCES users(id), UNIQUE(plugin_name, version) ); -- Vote audit records with version info CREATE TABLE IF NOT EXISTS vote_audit ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE, voting_method VARCHAR(50) NOT NULL, plugin_version VARCHAR(20) NOT NULL, plugin_hash VARCHAR(64), -- Snapshot of inputs options_snapshot JSONB NOT NULL, -- Options at time of vote close votes_count INT NOT NULL, voters_count INT NOT NULL, -- Calculated results results_snapshot JSONB NOT NULL, -- Full results at time of close winner_option_id UUID, -- Verification input_hash VARCHAR(64) NOT NULL, -- SHA256 of (options + votes) result_hash VARCHAR(64) NOT NULL, -- SHA256 of results -- Metadata closed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), verified_at TIMESTAMPTZ, verified_by UUID REFERENCES users(id) ); -- Function to record plugin version when voting starts CREATE OR REPLACE FUNCTION record_voting_plugin_version() RETURNS TRIGGER AS $$ DECLARE v_version VARCHAR(20); v_hash VARCHAR(64); BEGIN -- Only trigger when transitioning TO voting status IF NEW.status = 'voting' AND (OLD.status IS NULL OR OLD.status != 'voting') THEN -- Get current version of the voting method plugin SELECT COALESCE(pv.version, '1.0.0'), COALESCE(pv.wasm_hash, md5(vmp.name)::varchar) INTO v_version, v_hash FROM voting_method_plugins vmp LEFT JOIN plugin_versions pv ON pv.plugin_id = vmp.id AND pv.is_current = TRUE WHERE vmp.name = NEW.voting_method; -- If no version found, use built-in default IF v_version IS NULL THEN v_version := '1.0.0-builtin'; v_hash := md5(NEW.voting_method)::varchar; END IF; NEW.voting_plugin_version := v_version; NEW.voting_plugin_hash := v_hash; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Create trigger for version recording DROP TRIGGER IF EXISTS record_voting_plugin_version_trigger ON proposals; CREATE TRIGGER record_voting_plugin_version_trigger BEFORE UPDATE ON proposals FOR EACH ROW EXECUTE FUNCTION record_voting_plugin_version(); -- Function to create vote audit record when voting closes CREATE OR REPLACE FUNCTION create_vote_audit_record() RETURNS TRIGGER AS $$ DECLARE v_options JSONB; v_results JSONB; v_votes_count INT; v_voters_count INT; v_winner_id UUID; v_input_hash VARCHAR(64); v_result_hash VARCHAR(64); BEGIN -- Only trigger when transitioning TO closed status IF NEW.status = 'closed' AND OLD.status = 'voting' THEN -- Gather options snapshot SELECT jsonb_agg(jsonb_build_object( 'id', po.id, 'label', po.label, 'sort_order', po.sort_order ) ORDER BY po.sort_order) INTO v_options FROM proposal_options po WHERE po.proposal_id = NEW.id; -- Count votes and voters SELECT COUNT(*), COUNT(DISTINCT voter_id) INTO v_votes_count, v_voters_count FROM votes WHERE proposal_id = NEW.id; -- Get winner (option with most votes) SELECT option_id INTO v_winner_id FROM votes WHERE proposal_id = NEW.id GROUP BY option_id ORDER BY COUNT(*) DESC LIMIT 1; -- Build results snapshot SELECT jsonb_agg(jsonb_build_object( 'option_id', r.option_id, 'label', po.label, 'vote_count', r.vote_count ) ORDER BY r.vote_count DESC) INTO v_results FROM ( SELECT option_id, COUNT(*) as vote_count FROM votes WHERE proposal_id = NEW.id GROUP BY option_id ) r JOIN proposal_options po ON po.id = r.option_id; -- Calculate hashes for integrity v_input_hash := md5(v_options::text || v_votes_count::text)::varchar; v_result_hash := md5(COALESCE(v_results::text, ''))::varchar; -- Insert audit record INSERT INTO vote_audit ( proposal_id, voting_method, plugin_version, plugin_hash, options_snapshot, votes_count, voters_count, results_snapshot, winner_option_id, input_hash, result_hash, closed_at ) VALUES ( NEW.id, NEW.voting_method, COALESCE(NEW.voting_plugin_version, '1.0.0-builtin'), NEW.voting_plugin_hash, COALESCE(v_options, '[]'::jsonb), v_votes_count, v_voters_count, COALESCE(v_results, '[]'::jsonb), v_winner_id, v_input_hash, v_result_hash, NOW() ); END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Create trigger for audit record DROP TRIGGER IF EXISTS create_vote_audit_trigger ON proposals; CREATE TRIGGER create_vote_audit_trigger AFTER UPDATE ON proposals FOR EACH ROW EXECUTE FUNCTION create_vote_audit_record(); -- Seed archive with built-in voting methods INSERT INTO plugin_wasm_archive (plugin_name, version, wasm_hash, algorithm_description) VALUES ('approval', '1.0.0-builtin', md5('approval')::varchar, 'Approval Voting: Voters select any number of options. Winner is option with most approvals.'), ('ranked_choice', '1.0.0-builtin', md5('ranked_choice')::varchar, 'Ranked Choice (IRV): Voters rank options. Lowest-ranked eliminated iteratively until majority.'), ('schulze', '1.0.0-builtin', md5('schulze')::varchar, 'Schulze Method: Condorcet-consistent pairwise comparison. Finds strongest path winner.'), ('star', '1.0.0-builtin', md5('star')::varchar, 'STAR Voting: Score Then Automatic Runoff. Top two scorers face head-to-head runoff.'), ('quadratic', '1.0.0-builtin', md5('quadratic')::varchar, 'Quadratic Voting: Cost = votes². Allows expressing preference intensity with budget constraint.') ON CONFLICT (plugin_name, version) DO NOTHING; -- Indexes for audit queries CREATE INDEX IF NOT EXISTS idx_vote_audit_proposal ON vote_audit(proposal_id); CREATE INDEX IF NOT EXISTS idx_vote_audit_closed ON vote_audit(closed_at); CREATE INDEX IF NOT EXISTS idx_vote_audit_method ON vote_audit(voting_method); CREATE INDEX IF NOT EXISTS idx_plugin_archive_name ON plugin_wasm_archive(plugin_name); -- Function to verify a past vote result CREATE OR REPLACE FUNCTION verify_vote_result(p_proposal_id UUID) RETURNS TABLE( is_valid BOOLEAN, recorded_hash VARCHAR(64), computed_hash VARCHAR(64), details TEXT ) AS $$ DECLARE v_audit vote_audit%ROWTYPE; v_current_results JSONB; v_computed_hash VARCHAR(64); BEGIN -- Get audit record SELECT * INTO v_audit FROM vote_audit WHERE proposal_id = p_proposal_id; IF NOT FOUND THEN RETURN QUERY SELECT FALSE, NULL::VARCHAR, NULL::VARCHAR, 'No audit record found'; RETURN; END IF; -- Recompute results from current data SELECT jsonb_agg(jsonb_build_object( 'option_id', r.option_id, 'label', po.label, 'vote_count', r.vote_count ) ORDER BY r.vote_count DESC) INTO v_current_results FROM ( SELECT option_id, COUNT(*) as vote_count FROM votes WHERE proposal_id = p_proposal_id GROUP BY option_id ) r JOIN proposal_options po ON po.id = r.option_id; v_computed_hash := md5(COALESCE(v_current_results::text, ''))::varchar; -- Compare IF v_computed_hash = v_audit.result_hash THEN RETURN QUERY SELECT TRUE, v_audit.result_hash, v_computed_hash, 'Vote results verified successfully'; ELSE RETURN QUERY SELECT FALSE, v_audit.result_hash, v_computed_hash, 'Vote results do not match audit record'; END IF; END; $$ LANGUAGE plpgsql; -- Historical voting power reconstruction CREATE OR REPLACE FUNCTION get_voting_power_at( p_user_id UUID, p_community_id UUID, p_at_time TIMESTAMPTZ ) RETURNS TABLE( delegator_id UUID, delegator_username VARCHAR, effective_weight DECIMAL, chain_depth INT ) AS $$ BEGIN RETURN QUERY WITH RECURSIVE delegation_tree AS ( -- Base: direct delegations to this user at the given time SELECT d.delegator_id, d.delegate_id, d.weight, 1 as depth, ARRAY[d.delegator_id] as path FROM delegations d WHERE d.delegate_id = p_user_id AND (d.community_id = p_community_id OR d.scope = 'global') AND d.is_active = TRUE AND d.created_at <= p_at_time AND (d.revoked_at IS NULL OR d.revoked_at > p_at_time) UNION ALL -- Recursive: delegations to people who delegated to us SELECT d2.delegator_id, d2.delegate_id, dt.weight * d2.weight, dt.depth + 1, dt.path || d2.delegator_id FROM delegation_tree dt JOIN delegations d2 ON d2.delegate_id = dt.delegator_id WHERE dt.depth < 20 -- Max chain depth AND NOT (d2.delegator_id = ANY(dt.path)) -- Prevent cycles AND (d2.community_id = p_community_id OR d2.scope = 'global') AND d2.is_active = TRUE AND d2.created_at <= p_at_time AND (d2.revoked_at IS NULL OR d2.revoked_at > p_at_time) ) SELECT dt.delegator_id, u.username, dt.weight::DECIMAL, dt.depth FROM delegation_tree dt JOIN users u ON u.id = dt.delegator_id ORDER BY dt.depth, dt.weight DESC; END; $$ LANGUAGE plpgsql;