-- ============================================================================ -- PROPOSAL LIFECYCLE PLUGIN -- Draft → Review → Active → Archived with versioning, diffs, and forks -- ============================================================================ -- ============================================================================ -- PROPOSAL LIFECYCLE STATUS -- Extended status tracking beyond basic states -- ============================================================================ CREATE TYPE proposal_lifecycle_status AS ENUM ( 'draft', -- Initial creation, not yet submitted 'submitted', -- Submitted for review 'review', -- Under community/moderator review 'revision', -- Sent back for revision 'active', -- Open for discussion/voting 'voting', -- In voting phase 'passed', -- Voting passed, pending implementation 'rejected', -- Voting rejected 'implemented', -- Successfully implemented 'archived', -- Archived (completed or abandoned) 'withdrawn' -- Withdrawn by author ); -- ============================================================================ -- PROPOSAL VERSIONS -- Complete version history with semantic diffing -- ============================================================================ CREATE TABLE proposal_versions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE, version_number INT NOT NULL, -- Version content (full snapshot) title VARCHAR(500) NOT NULL, content TEXT NOT NULL, summary TEXT, -- Metadata created_by UUID NOT NULL REFERENCES users(id), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Change tracking change_type VARCHAR(50) NOT NULL DEFAULT 'edit', -- create, edit, amendment, merge change_summary TEXT, -- Diff from previous version diff_from_previous JSONB, -- Structured diff data -- Status at this version status_at_version proposal_lifecycle_status NOT NULL, -- Review info reviewed_by UUID REFERENCES users(id), reviewed_at TIMESTAMPTZ, review_notes TEXT, UNIQUE(proposal_id, version_number) ); CREATE INDEX idx_proposal_versions_proposal ON proposal_versions(proposal_id); CREATE INDEX idx_proposal_versions_created ON proposal_versions(proposal_id, created_at); CREATE INDEX idx_proposal_versions_author ON proposal_versions(created_by); COMMENT ON TABLE proposal_versions IS 'Complete version history for proposals'; -- ============================================================================ -- PROPOSAL LIFECYCLE TRACKING -- Extended lifecycle metadata -- ============================================================================ CREATE TABLE proposal_lifecycle ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE UNIQUE, -- Current state current_status proposal_lifecycle_status NOT NULL DEFAULT 'draft', current_version INT NOT NULL DEFAULT 1, -- Timing submitted_at TIMESTAMPTZ, review_started_at TIMESTAMPTZ, activated_at TIMESTAMPTZ, voting_started_at TIMESTAMPTZ, voting_ended_at TIMESTAMPTZ, resolved_at TIMESTAMPTZ, archived_at TIMESTAMPTZ, -- Review tracking review_count INT NOT NULL DEFAULT 0, revision_count INT NOT NULL DEFAULT 0, -- Fork tracking forked_from_id UUID REFERENCES proposals(id), fork_count INT NOT NULL DEFAULT 0, -- Amendment tracking amendment_count INT NOT NULL DEFAULT 0, merged_amendments JSONB DEFAULT '[]', -- Metadata lifecycle_config JSONB NOT NULL DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_proposal_lifecycle_proposal ON proposal_lifecycle(proposal_id); CREATE INDEX idx_proposal_lifecycle_status ON proposal_lifecycle(current_status); CREATE INDEX idx_proposal_lifecycle_forked ON proposal_lifecycle(forked_from_id); COMMENT ON TABLE proposal_lifecycle IS 'Extended lifecycle tracking for proposals'; -- ============================================================================ -- PROPOSAL STATUS TRANSITIONS -- Audit log of all status changes -- ============================================================================ CREATE TABLE proposal_status_transitions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE, -- Transition from_status proposal_lifecycle_status, to_status proposal_lifecycle_status NOT NULL, -- Actor triggered_by UUID REFERENCES users(id), trigger_type VARCHAR(50) NOT NULL, -- manual, auto, vote, workflow -- Context reason TEXT, metadata JSONB NOT NULL DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_status_transitions_proposal ON proposal_status_transitions(proposal_id); CREATE INDEX idx_status_transitions_time ON proposal_status_transitions(created_at); COMMENT ON TABLE proposal_status_transitions IS 'Audit trail of proposal status changes'; -- ============================================================================ -- PROPOSAL FORKS -- Track proposal forks (very FLOSS-friendly) -- ============================================================================ CREATE TABLE proposal_forks ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), -- Source source_proposal_id UUID NOT NULL REFERENCES proposals(id), source_version_number INT NOT NULL, -- Fork fork_proposal_id UUID NOT NULL REFERENCES proposals(id) UNIQUE, -- Metadata forked_by UUID NOT NULL REFERENCES users(id), forked_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), fork_reason TEXT, -- Relationship status is_competing BOOLEAN NOT NULL DEFAULT FALSE, -- Competing alternative is_merged BOOLEAN NOT NULL DEFAULT FALSE, -- Merged back merged_at TIMESTAMPTZ ); CREATE INDEX idx_proposal_forks_source ON proposal_forks(source_proposal_id); CREATE INDEX idx_proposal_forks_fork ON proposal_forks(fork_proposal_id); COMMENT ON TABLE proposal_forks IS 'Proposal fork relationships'; -- ============================================================================ -- PROPOSAL AMENDMENTS -- Suggested changes from community -- ============================================================================ CREATE TYPE amendment_status AS ENUM ( 'proposed', -- Suggested by community member 'under_review', -- Being reviewed by author/moderators 'accepted', -- Accepted and incorporated 'rejected', -- Rejected by author 'withdrawn', -- Withdrawn by proposer 'superseded' -- Superseded by another amendment ); CREATE TABLE proposal_amendments ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE, target_version INT NOT NULL, -- Amendment content title VARCHAR(200) NOT NULL, description TEXT NOT NULL, suggested_changes JSONB NOT NULL, -- Structured change suggestions -- Author proposed_by UUID NOT NULL REFERENCES users(id), proposed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Status status amendment_status NOT NULL DEFAULT 'proposed', -- Review reviewed_by UUID REFERENCES users(id), reviewed_at TIMESTAMPTZ, review_response TEXT, -- If accepted incorporated_in_version INT, -- Voting (if community votes on amendments) vote_required BOOLEAN NOT NULL DEFAULT FALSE, vote_result JSONB, -- Support tracking support_count INT NOT NULL DEFAULT 0, oppose_count INT NOT NULL DEFAULT 0 ); CREATE INDEX idx_amendments_proposal ON proposal_amendments(proposal_id); CREATE INDEX idx_amendments_status ON proposal_amendments(status); CREATE INDEX idx_amendments_author ON proposal_amendments(proposed_by); COMMENT ON TABLE proposal_amendments IS 'Community-suggested amendments to proposals'; -- ============================================================================ -- AMENDMENT SUPPORT -- Track support/opposition for amendments -- ============================================================================ CREATE TABLE amendment_support ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), amendment_id UUID NOT NULL REFERENCES proposal_amendments(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(id), support_type VARCHAR(20) NOT NULL, -- support, oppose, neutral comment TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(amendment_id, user_id) ); CREATE INDEX idx_amendment_support_amendment ON amendment_support(amendment_id); -- ============================================================================ -- HELPER FUNCTIONS -- ============================================================================ -- Create a new version of a proposal CREATE OR REPLACE FUNCTION create_proposal_version( p_proposal_id UUID, p_title VARCHAR(500), p_content TEXT, p_summary TEXT, p_created_by UUID, p_change_type VARCHAR(50), p_change_summary TEXT ) RETURNS INT AS $$ DECLARE v_version_number INT; v_previous_content TEXT; v_current_status proposal_lifecycle_status; BEGIN -- Get current version number and content SELECT current_version INTO v_version_number FROM proposal_lifecycle WHERE proposal_id = p_proposal_id; IF v_version_number IS NULL THEN v_version_number := 0; END IF; v_version_number := v_version_number + 1; -- Get previous content for diff SELECT content INTO v_previous_content FROM proposal_versions WHERE proposal_id = p_proposal_id ORDER BY version_number DESC LIMIT 1; -- Get current status SELECT COALESCE(current_status, 'draft') INTO v_current_status FROM proposal_lifecycle WHERE proposal_id = p_proposal_id; -- Create version INSERT INTO proposal_versions ( proposal_id, version_number, title, content, summary, created_by, change_type, change_summary, status_at_version, diff_from_previous ) VALUES ( p_proposal_id, v_version_number, p_title, p_content, p_summary, p_created_by, p_change_type, p_change_summary, v_current_status, CASE WHEN v_previous_content IS NOT NULL THEN jsonb_build_object( 'type', 'text_diff', 'previous_length', LENGTH(v_previous_content), 'new_length', LENGTH(p_content), 'changed', v_previous_content != p_content ) ELSE NULL END ); -- Update lifecycle INSERT INTO proposal_lifecycle (proposal_id, current_version) VALUES (p_proposal_id, v_version_number) ON CONFLICT (proposal_id) DO UPDATE SET current_version = v_version_number, revision_count = proposal_lifecycle.revision_count + 1, updated_at = NOW(); RETURN v_version_number; END; $$ LANGUAGE plpgsql; -- Transition proposal status CREATE OR REPLACE FUNCTION transition_proposal_status( p_proposal_id UUID, p_new_status proposal_lifecycle_status, p_triggered_by UUID, p_trigger_type VARCHAR(50), p_reason TEXT DEFAULT NULL ) RETURNS BOOLEAN AS $$ DECLARE v_current_status proposal_lifecycle_status; v_valid_transition BOOLEAN := FALSE; BEGIN -- Get current status SELECT current_status INTO v_current_status FROM proposal_lifecycle WHERE proposal_id = p_proposal_id; -- Validate transition (simplified - can be expanded) v_valid_transition := CASE v_current_status WHEN 'draft' THEN p_new_status IN ('submitted', 'withdrawn') WHEN 'submitted' THEN p_new_status IN ('review', 'revision', 'withdrawn') WHEN 'review' THEN p_new_status IN ('revision', 'active', 'rejected') WHEN 'revision' THEN p_new_status IN ('submitted', 'withdrawn') WHEN 'active' THEN p_new_status IN ('voting', 'archived', 'withdrawn') WHEN 'voting' THEN p_new_status IN ('passed', 'rejected') WHEN 'passed' THEN p_new_status IN ('implemented', 'archived') WHEN 'rejected' THEN p_new_status IN ('revision', 'archived') WHEN 'implemented' THEN p_new_status IN ('archived') ELSE FALSE END; IF NOT v_valid_transition THEN RETURN FALSE; END IF; -- Log transition INSERT INTO proposal_status_transitions ( proposal_id, from_status, to_status, triggered_by, trigger_type, reason ) VALUES ( p_proposal_id, v_current_status, p_new_status, p_triggered_by, p_trigger_type, p_reason ); -- Update lifecycle UPDATE proposal_lifecycle SET current_status = p_new_status, updated_at = NOW(), submitted_at = CASE WHEN p_new_status = 'submitted' THEN NOW() ELSE submitted_at END, review_started_at = CASE WHEN p_new_status = 'review' THEN NOW() ELSE review_started_at END, activated_at = CASE WHEN p_new_status = 'active' THEN NOW() ELSE activated_at END, voting_started_at = CASE WHEN p_new_status = 'voting' THEN NOW() ELSE voting_started_at END, voting_ended_at = CASE WHEN p_new_status IN ('passed', 'rejected') THEN NOW() ELSE voting_ended_at END, resolved_at = CASE WHEN p_new_status IN ('implemented', 'rejected', 'withdrawn') THEN NOW() ELSE resolved_at END, archived_at = CASE WHEN p_new_status = 'archived' THEN NOW() ELSE archived_at END WHERE proposal_id = p_proposal_id; RETURN TRUE; END; $$ LANGUAGE plpgsql; -- Fork a proposal CREATE OR REPLACE FUNCTION fork_proposal( p_source_proposal_id UUID, p_forked_by UUID, p_fork_reason TEXT, p_community_id UUID ) RETURNS UUID AS $$ DECLARE v_source_version INT; v_source_title VARCHAR(500); v_source_content TEXT; v_new_proposal_id UUID; BEGIN -- Get source proposal latest version SELECT pv.version_number, pv.title, pv.content INTO v_source_version, v_source_title, v_source_content FROM proposal_versions pv JOIN proposal_lifecycle pl ON pl.proposal_id = pv.proposal_id WHERE pv.proposal_id = p_source_proposal_id AND pv.version_number = pl.current_version; -- Create new proposal INSERT INTO proposals (community_id, author_id, title, content, status) VALUES (p_community_id, p_forked_by, '[Fork] ' || v_source_title, v_source_content, 'draft') RETURNING id INTO v_new_proposal_id; -- Initialize lifecycle INSERT INTO proposal_lifecycle (proposal_id, current_status, forked_from_id) VALUES (v_new_proposal_id, 'draft', p_source_proposal_id); -- Create initial version PERFORM create_proposal_version( v_new_proposal_id, '[Fork] ' || v_source_title, v_source_content, 'Forked from proposal ' || p_source_proposal_id, p_forked_by, 'create', 'Fork created' ); -- Record fork relationship INSERT INTO proposal_forks ( source_proposal_id, source_version_number, fork_proposal_id, forked_by, fork_reason ) VALUES ( p_source_proposal_id, v_source_version, v_new_proposal_id, p_forked_by, p_fork_reason ); -- Update source fork count UPDATE proposal_lifecycle SET fork_count = fork_count + 1 WHERE proposal_id = p_source_proposal_id; RETURN v_new_proposal_id; END; $$ LANGUAGE plpgsql; -- ============================================================================ -- VIEWS -- ============================================================================ CREATE OR REPLACE VIEW proposal_lifecycle_summary AS SELECT p.id AS proposal_id, p.title, p.community_id, c.name AS community_name, pl.current_status::text AS status, pl.current_version, pl.submitted_at, pl.activated_at, pl.voting_started_at, pl.resolved_at, pl.revision_count, pl.fork_count, pl.amendment_count, pl.forked_from_id, u.username AS author_username, p.created_at FROM proposals p JOIN proposal_lifecycle pl ON pl.proposal_id = p.id JOIN communities c ON c.id = p.community_id JOIN users u ON u.id = p.author_id ORDER BY p.created_at DESC; CREATE OR REPLACE VIEW proposal_version_history AS SELECT pv.proposal_id, pv.version_number, pv.title, pv.change_type, pv.change_summary, pv.status_at_version::text AS status, u.username AS author_username, pv.created_at, pv.reviewed_by IS NOT NULL AS was_reviewed FROM proposal_versions pv JOIN users u ON u.id = pv.created_by ORDER BY pv.proposal_id, pv.version_number DESC; -- ============================================================================ -- TRIGGERS -- ============================================================================ -- Auto-initialize lifecycle when proposal is created CREATE OR REPLACE FUNCTION auto_init_proposal_lifecycle() RETURNS TRIGGER AS $$ BEGIN INSERT INTO proposal_lifecycle (proposal_id, current_status) VALUES (NEW.id, 'draft') ON CONFLICT DO NOTHING; -- Create initial version INSERT INTO proposal_versions ( proposal_id, version_number, title, content, created_by, change_type, status_at_version ) VALUES ( NEW.id, 1, NEW.title, NEW.description, NEW.author_id, 'create', 'draft' ) ON CONFLICT DO NOTHING; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER trg_auto_init_proposal_lifecycle AFTER INSERT ON proposals FOR EACH ROW EXECUTE FUNCTION auto_init_proposal_lifecycle(); -- ============================================================================ -- PLUGIN REGISTRATION -- ============================================================================ INSERT INTO plugins (name, description, version, is_core, is_active, settings_schema) VALUES ( 'proposal_lifecycle', 'Complete proposal lifecycle management with versioning, semantic diffs, amendments, and FLOSS-style forking. Tracks Draft → Review → Active → Archived transitions.', '1.0.0', true, true, jsonb_build_object( 'type', 'object', 'properties', jsonb_build_object( 'require_review', jsonb_build_object( 'type', 'boolean', 'title', 'Require Review', 'description', 'Require moderator review before proposals become active', 'default', true ), 'allow_forks', jsonb_build_object( 'type', 'boolean', 'title', 'Allow Forks', 'description', 'Allow community members to fork proposals', 'default', true ), 'allow_amendments', jsonb_build_object( 'type', 'boolean', 'title', 'Allow Amendments', 'description', 'Allow community members to suggest amendments', 'default', true ), 'amendment_vote_threshold', jsonb_build_object( 'type', 'integer', 'title', 'Amendment Vote Threshold', 'description', 'Support count required before amendment is considered', 'default', 5, 'minimum', 1 ), 'max_revisions', jsonb_build_object( 'type', 'integer', 'title', 'Max Revisions', 'description', 'Maximum times a proposal can be sent back for revision', 'default', 3, 'minimum', 1, 'maximum', 10 ) ) ) ) ON CONFLICT (name) DO UPDATE SET version = EXCLUDED.version, description = EXCLUDED.description;