-- Topic-based Voting Method Assignment -- Allows different voting methods for different topics within a community -- Topic-specific voting method configuration CREATE TABLE IF NOT EXISTS topic_voting_methods ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), topic_id UUID NOT NULL REFERENCES topics(id) ON DELETE CASCADE, voting_method_id UUID NOT NULL REFERENCES voting_method_plugins(id) ON DELETE CASCADE, is_enabled BOOLEAN NOT NULL DEFAULT TRUE, is_default BOOLEAN NOT NULL DEFAULT FALSE, config JSONB DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(topic_id, voting_method_id) ); -- Voting phase configurations for granular control CREATE TABLE IF NOT EXISTS voting_phase_configs ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), -- Can be applied at community or topic level community_id UUID REFERENCES communities(id) ON DELETE CASCADE, topic_id UUID REFERENCES topics(id) ON DELETE CASCADE, -- Phase durations (in hours, NULL = unlimited/manual) inform_duration_hours INT, discuss_duration_hours INT, voting_duration_hours INT, -- Phase requirements require_inform_phase BOOLEAN NOT NULL DEFAULT FALSE, require_discuss_phase BOOLEAN NOT NULL DEFAULT TRUE, min_discussion_comments INT DEFAULT 0, min_read_time_seconds INT DEFAULT 0, -- Quorum settings quorum_type VARCHAR(20) DEFAULT 'none', -- 'none', 'percentage', 'absolute' quorum_value INT DEFAULT 0, -- percentage (0-100) or absolute number -- Auto-transitions auto_start_discussion BOOLEAN NOT NULL DEFAULT FALSE, auto_start_voting BOOLEAN NOT NULL DEFAULT FALSE, auto_close_voting BOOLEAN NOT NULL DEFAULT TRUE, -- Notifications notify_phase_changes BOOLEAN NOT NULL DEFAULT TRUE, notify_before_close_hours INT DEFAULT 24, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Ensure only one of community_id or topic_id is set (or neither for defaults) CONSTRAINT phase_config_scope CHECK ( (community_id IS NOT NULL AND topic_id IS NULL) OR (community_id IS NULL AND topic_id IS NOT NULL) OR (community_id IS NULL AND topic_id IS NULL) ) ); -- Phase transition log for audit CREATE TABLE IF NOT EXISTS phase_transitions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE, from_phase VARCHAR(20), to_phase VARCHAR(20) NOT NULL, triggered_by VARCHAR(20) NOT NULL, -- 'manual', 'auto', 'system' triggered_by_user_id UUID REFERENCES users(id), metadata JSONB, transitioned_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Function to get effective voting method for a proposal CREATE OR REPLACE FUNCTION get_proposal_voting_method(p_proposal_id UUID) RETURNS TABLE( method_name VARCHAR, method_id UUID, config JSONB ) AS $$ DECLARE v_topic_id UUID; v_community_id UUID; BEGIN -- Get proposal's topic and community SELECT topic_id, community_id INTO v_topic_id, v_community_id FROM proposals WHERE id = p_proposal_id; -- Priority: Topic default > Community default > Platform default -- Try topic-level IF v_topic_id IS NOT NULL THEN RETURN QUERY SELECT vm.name, vm.id, tvm.config FROM topic_voting_methods tvm JOIN voting_method_plugins vm ON vm.id = tvm.voting_method_id WHERE tvm.topic_id = v_topic_id AND tvm.is_default = TRUE AND tvm.is_enabled = TRUE LIMIT 1; IF FOUND THEN RETURN; END IF; END IF; -- Try community-level RETURN QUERY SELECT vm.name, vm.id, cvm.config FROM community_voting_methods cvm JOIN voting_method_plugins vm ON vm.id = cvm.voting_method_id WHERE cvm.community_id = v_community_id AND cvm.is_default = TRUE AND cvm.is_enabled = TRUE LIMIT 1; IF FOUND THEN RETURN; END IF; -- Fall back to platform default RETURN QUERY SELECT vm.name, vm.id, vm.default_config FROM voting_method_plugins vm WHERE vm.is_default = TRUE AND vm.is_active = TRUE LIMIT 1; END; $$ LANGUAGE plpgsql; -- Function to get effective phase config for a proposal CREATE OR REPLACE FUNCTION get_proposal_phase_config(p_proposal_id UUID) RETURNS voting_phase_configs AS $$ DECLARE v_topic_id UUID; v_community_id UUID; v_config voting_phase_configs; BEGIN -- Get proposal's topic and community SELECT topic_id, community_id INTO v_topic_id, v_community_id FROM proposals WHERE id = p_proposal_id; -- Try topic-level config IF v_topic_id IS NOT NULL THEN SELECT * INTO v_config FROM voting_phase_configs WHERE topic_id = v_topic_id LIMIT 1; IF FOUND THEN RETURN v_config; END IF; END IF; -- Try community-level config SELECT * INTO v_config FROM voting_phase_configs WHERE community_id = v_community_id LIMIT 1; IF FOUND THEN RETURN v_config; END IF; -- Return default config (all NULLs will use system defaults) SELECT * INTO v_config FROM voting_phase_configs WHERE community_id IS NULL AND topic_id IS NULL LIMIT 1; RETURN v_config; END; $$ LANGUAGE plpgsql; -- Function to check if proposal meets quorum CREATE OR REPLACE FUNCTION check_proposal_quorum(p_proposal_id UUID) RETURNS BOOLEAN AS $$ DECLARE v_config voting_phase_configs; v_community_id UUID; v_member_count INT; v_vote_count INT; v_required INT; BEGIN v_config := get_proposal_phase_config(p_proposal_id); -- No quorum requirement IF v_config.quorum_type IS NULL OR v_config.quorum_type = 'none' THEN RETURN TRUE; END IF; -- Get community and counts SELECT community_id INTO v_community_id FROM proposals WHERE id = p_proposal_id; SELECT COUNT(*) INTO v_member_count FROM community_members WHERE community_id = v_community_id; SELECT COUNT(DISTINCT voter_id) INTO v_vote_count FROM votes WHERE proposal_id = p_proposal_id; -- Calculate required votes IF v_config.quorum_type = 'percentage' THEN v_required := CEIL(v_member_count * v_config.quorum_value / 100.0); ELSE -- absolute v_required := v_config.quorum_value; END IF; RETURN v_vote_count >= v_required; END; $$ LANGUAGE plpgsql; -- Insert default phase config INSERT INTO voting_phase_configs ( require_inform_phase, require_discuss_phase, min_discussion_comments, auto_start_discussion, auto_start_voting, auto_close_voting, notify_phase_changes ) VALUES ( FALSE, TRUE, 0, FALSE, FALSE, TRUE, TRUE ) ON CONFLICT DO NOTHING; -- Indexes CREATE INDEX IF NOT EXISTS idx_topic_voting_methods_topic ON topic_voting_methods(topic_id); CREATE INDEX IF NOT EXISTS idx_voting_phase_configs_community ON voting_phase_configs(community_id); CREATE INDEX IF NOT EXISTS idx_voting_phase_configs_topic ON voting_phase_configs(topic_id); CREATE INDEX IF NOT EXISTS idx_phase_transitions_proposal ON phase_transitions(proposal_id); CREATE INDEX IF NOT EXISTS idx_phase_transitions_time ON phase_transitions(transitioned_at); -- Triggers CREATE TRIGGER topic_voting_methods_updated_at BEFORE UPDATE ON topic_voting_methods FOR EACH ROW EXECUTE FUNCTION update_updated_at(); CREATE TRIGGER voting_phase_configs_updated_at BEFORE UPDATE ON voting_phase_configs FOR EACH ROW EXECUTE FUNCTION update_updated_at();