mirror of
https://codeberg.org/likwid/likwid.git
synced 2026-02-09 21:13:09 +00:00
- Backend: Rust/Axum with PostgreSQL, plugin architecture - Frontend: Astro with polished UI - Voting methods: Approval, Ranked Choice, Schulze, STAR, Quadratic - Features: Liquid delegation, transparent moderation, structured deliberation - Documentation: User and admin guides in /docs - Deployment: Docker/Podman compose files for production and demo - Demo: Seeded data with 3 communities, 13 users, 7 proposals License: AGPLv3
611 lines
24 KiB
PL/PgSQL
611 lines
24 KiB
PL/PgSQL
-- ============================================================================
|
|
-- DECISION-MAKING PROCESSES PLUGIN
|
|
-- Composable decision-making workflows with configurable phases
|
|
-- ============================================================================
|
|
|
|
-- ============================================================================
|
|
-- WORKFLOW TEMPLATES
|
|
-- Reusable workflow definitions that can be applied to proposals
|
|
-- ============================================================================
|
|
|
|
CREATE TABLE workflow_templates (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
community_id UUID REFERENCES communities(id) ON DELETE CASCADE,
|
|
name VARCHAR(100) NOT NULL,
|
|
description TEXT,
|
|
is_default BOOLEAN NOT NULL DEFAULT FALSE,
|
|
is_system BOOLEAN NOT NULL DEFAULT FALSE,
|
|
config JSONB NOT NULL DEFAULT '{}',
|
|
created_by UUID REFERENCES users(id),
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
UNIQUE(community_id, name)
|
|
);
|
|
|
|
CREATE INDEX idx_workflow_templates_community ON workflow_templates(community_id);
|
|
CREATE INDEX idx_workflow_templates_default ON workflow_templates(community_id, is_default) WHERE is_default = true;
|
|
|
|
COMMENT ON TABLE workflow_templates IS 'Reusable workflow definitions for decision-making processes';
|
|
|
|
-- ============================================================================
|
|
-- WORKFLOW PHASES
|
|
-- Individual phases within a workflow (discussion, amendment, vote, etc.)
|
|
-- ============================================================================
|
|
|
|
CREATE TYPE workflow_phase_type AS ENUM (
|
|
'discussion', -- Open discussion period
|
|
'amendment', -- Proposal amendment/refinement period
|
|
'review', -- Expert/committee review period
|
|
'vote', -- Active voting period
|
|
'runoff', -- Runoff voting if needed
|
|
'ratification', -- Final ratification/approval
|
|
'implementation', -- Implementation tracking
|
|
'cooldown', -- Waiting period between phases
|
|
'custom' -- Custom phase type
|
|
);
|
|
|
|
CREATE TABLE workflow_phases (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
template_id UUID NOT NULL REFERENCES workflow_templates(id) ON DELETE CASCADE,
|
|
name VARCHAR(100) NOT NULL,
|
|
phase_type workflow_phase_type NOT NULL,
|
|
sequence_order INT NOT NULL,
|
|
description TEXT,
|
|
|
|
-- Duration configuration
|
|
min_duration_hours INT,
|
|
max_duration_hours INT,
|
|
default_duration_hours INT NOT NULL DEFAULT 168, -- 1 week
|
|
allow_early_completion BOOLEAN NOT NULL DEFAULT FALSE,
|
|
|
|
-- Quorum configuration
|
|
quorum_type VARCHAR(50) NOT NULL DEFAULT 'percentage', -- percentage, absolute, adaptive
|
|
quorum_value DECIMAL(10, 4) NOT NULL DEFAULT 0.10, -- 10% default
|
|
quorum_scope VARCHAR(50) NOT NULL DEFAULT 'community', -- community, participants, delegated
|
|
|
|
-- Participation requirements
|
|
require_reading BOOLEAN NOT NULL DEFAULT FALSE,
|
|
require_comment BOOLEAN NOT NULL DEFAULT FALSE,
|
|
min_unique_participants INT,
|
|
|
|
-- Transition rules
|
|
auto_advance BOOLEAN NOT NULL DEFAULT TRUE,
|
|
advance_condition JSONB NOT NULL DEFAULT '{"type": "duration"}',
|
|
failure_action VARCHAR(50) NOT NULL DEFAULT 'reject', -- reject, extend, escalate, restart
|
|
|
|
-- Phase-specific config
|
|
phase_config JSONB NOT NULL DEFAULT '{}',
|
|
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
UNIQUE(template_id, sequence_order)
|
|
);
|
|
|
|
CREATE INDEX idx_workflow_phases_template ON workflow_phases(template_id);
|
|
CREATE INDEX idx_workflow_phases_order ON workflow_phases(template_id, sequence_order);
|
|
|
|
COMMENT ON TABLE workflow_phases IS 'Individual phases within a workflow template';
|
|
|
|
-- ============================================================================
|
|
-- PHASE DEPENDENCIES
|
|
-- Define dependencies between phases (e.g., vote requires discussion)
|
|
-- ============================================================================
|
|
|
|
CREATE TABLE phase_dependencies (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
phase_id UUID NOT NULL REFERENCES workflow_phases(id) ON DELETE CASCADE,
|
|
depends_on_phase_id UUID NOT NULL REFERENCES workflow_phases(id) ON DELETE CASCADE,
|
|
dependency_type VARCHAR(50) NOT NULL DEFAULT 'completion', -- completion, quorum_met, majority
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
UNIQUE(phase_id, depends_on_phase_id),
|
|
CHECK (phase_id != depends_on_phase_id)
|
|
);
|
|
|
|
CREATE INDEX idx_phase_dependencies_phase ON phase_dependencies(phase_id);
|
|
|
|
COMMENT ON TABLE phase_dependencies IS 'Dependencies between workflow phases';
|
|
|
|
-- ============================================================================
|
|
-- WORKFLOW INSTANCES
|
|
-- Active workflow instances attached to proposals
|
|
-- ============================================================================
|
|
|
|
CREATE TABLE workflow_instances (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
proposal_id UUID NOT NULL REFERENCES proposals(id) ON DELETE CASCADE,
|
|
template_id UUID NOT NULL REFERENCES workflow_templates(id),
|
|
current_phase_id UUID REFERENCES workflow_phases(id),
|
|
status VARCHAR(50) NOT NULL DEFAULT 'active', -- active, paused, completed, failed, cancelled
|
|
started_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
completed_at TIMESTAMPTZ,
|
|
failure_reason TEXT,
|
|
metadata JSONB NOT NULL DEFAULT '{}',
|
|
UNIQUE(proposal_id)
|
|
);
|
|
|
|
CREATE INDEX idx_workflow_instances_proposal ON workflow_instances(proposal_id);
|
|
CREATE INDEX idx_workflow_instances_status ON workflow_instances(status);
|
|
CREATE INDEX idx_workflow_instances_current_phase ON workflow_instances(current_phase_id);
|
|
|
|
COMMENT ON TABLE workflow_instances IS 'Active workflow instances for proposals';
|
|
|
|
-- ============================================================================
|
|
-- PHASE INSTANCES
|
|
-- Tracking individual phase executions
|
|
-- ============================================================================
|
|
|
|
CREATE TABLE phase_instances (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
workflow_instance_id UUID NOT NULL REFERENCES workflow_instances(id) ON DELETE CASCADE,
|
|
phase_id UUID NOT NULL REFERENCES workflow_phases(id),
|
|
status VARCHAR(50) NOT NULL DEFAULT 'pending', -- pending, active, completed, skipped, failed
|
|
|
|
-- Timing
|
|
scheduled_start TIMESTAMPTZ,
|
|
actual_start TIMESTAMPTZ,
|
|
scheduled_end TIMESTAMPTZ,
|
|
actual_end TIMESTAMPTZ,
|
|
extended_count INT NOT NULL DEFAULT 0,
|
|
|
|
-- Participation tracking
|
|
participant_count INT NOT NULL DEFAULT 0,
|
|
quorum_reached BOOLEAN NOT NULL DEFAULT FALSE,
|
|
quorum_reached_at TIMESTAMPTZ,
|
|
|
|
-- Results
|
|
result JSONB,
|
|
completion_reason VARCHAR(100), -- duration, quorum, manual, early_completion, failure
|
|
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
UNIQUE(workflow_instance_id, phase_id)
|
|
);
|
|
|
|
CREATE INDEX idx_phase_instances_workflow ON phase_instances(workflow_instance_id);
|
|
CREATE INDEX idx_phase_instances_status ON phase_instances(status);
|
|
CREATE INDEX idx_phase_instances_active ON phase_instances(status, scheduled_end) WHERE status = 'active';
|
|
|
|
COMMENT ON TABLE phase_instances IS 'Individual phase execution tracking';
|
|
|
|
-- ============================================================================
|
|
-- PHASE PARTICIPATION
|
|
-- Track who participated in each phase
|
|
-- ============================================================================
|
|
|
|
CREATE TABLE phase_participation (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
phase_instance_id UUID NOT NULL REFERENCES phase_instances(id) ON DELETE CASCADE,
|
|
user_id UUID NOT NULL REFERENCES users(id),
|
|
participation_type VARCHAR(50) NOT NULL, -- viewed, commented, voted, amended
|
|
participated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
metadata JSONB NOT NULL DEFAULT '{}',
|
|
UNIQUE(phase_instance_id, user_id, participation_type)
|
|
);
|
|
|
|
CREATE INDEX idx_phase_participation_instance ON phase_participation(phase_instance_id);
|
|
CREATE INDEX idx_phase_participation_user ON phase_participation(user_id);
|
|
|
|
COMMENT ON TABLE phase_participation IS 'Participation tracking per phase';
|
|
|
|
-- ============================================================================
|
|
-- WORKFLOW TRANSITIONS
|
|
-- Log of all phase transitions
|
|
-- ============================================================================
|
|
|
|
CREATE TABLE workflow_transitions (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
workflow_instance_id UUID NOT NULL REFERENCES workflow_instances(id) ON DELETE CASCADE,
|
|
from_phase_id UUID REFERENCES workflow_phases(id),
|
|
to_phase_id UUID REFERENCES workflow_phases(id),
|
|
transition_type VARCHAR(50) NOT NULL, -- advance, skip, restart, fail, complete
|
|
triggered_by VARCHAR(50) NOT NULL, -- auto, manual, quorum, timeout
|
|
triggered_by_user_id UUID REFERENCES users(id),
|
|
reason TEXT,
|
|
metadata JSONB NOT NULL DEFAULT '{}',
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
CREATE INDEX idx_workflow_transitions_instance ON workflow_transitions(workflow_instance_id);
|
|
CREATE INDEX idx_workflow_transitions_time ON workflow_transitions(created_at);
|
|
|
|
COMMENT ON TABLE workflow_transitions IS 'Audit log of workflow phase transitions';
|
|
|
|
-- ============================================================================
|
|
-- QUORUM SNAPSHOTS
|
|
-- Track quorum status over time
|
|
-- ============================================================================
|
|
|
|
CREATE TABLE quorum_snapshots (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
phase_instance_id UUID NOT NULL REFERENCES phase_instances(id) ON DELETE CASCADE,
|
|
snapshot_time TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
eligible_count INT NOT NULL,
|
|
participant_count INT NOT NULL,
|
|
quorum_required DECIMAL(10, 4) NOT NULL,
|
|
quorum_current DECIMAL(10, 4) NOT NULL,
|
|
is_met BOOLEAN NOT NULL,
|
|
calculation_details JSONB NOT NULL DEFAULT '{}'
|
|
);
|
|
|
|
CREATE INDEX idx_quorum_snapshots_instance ON quorum_snapshots(phase_instance_id);
|
|
CREATE INDEX idx_quorum_snapshots_time ON quorum_snapshots(phase_instance_id, snapshot_time);
|
|
|
|
COMMENT ON TABLE quorum_snapshots IS 'Historical quorum tracking for transparency';
|
|
|
|
-- ============================================================================
|
|
-- HELPER FUNCTIONS
|
|
-- ============================================================================
|
|
|
|
-- Calculate current quorum for a phase instance
|
|
CREATE OR REPLACE FUNCTION calculate_phase_quorum(p_phase_instance_id UUID)
|
|
RETURNS TABLE (
|
|
eligible_count INT,
|
|
participant_count INT,
|
|
quorum_required DECIMAL,
|
|
quorum_current DECIMAL,
|
|
is_met BOOLEAN
|
|
) AS $$
|
|
DECLARE
|
|
v_phase_id UUID;
|
|
v_workflow_instance_id UUID;
|
|
v_community_id UUID;
|
|
v_quorum_type VARCHAR(50);
|
|
v_quorum_value DECIMAL;
|
|
v_quorum_scope VARCHAR(50);
|
|
BEGIN
|
|
-- Get phase configuration
|
|
SELECT pi.phase_id, pi.workflow_instance_id, wp.quorum_type, wp.quorum_value, wp.quorum_scope
|
|
INTO v_phase_id, v_workflow_instance_id, v_quorum_type, v_quorum_value, v_quorum_scope
|
|
FROM phase_instances pi
|
|
JOIN workflow_phases wp ON wp.id = pi.phase_id
|
|
WHERE pi.id = p_phase_instance_id;
|
|
|
|
-- Get community
|
|
SELECT p.community_id INTO v_community_id
|
|
FROM workflow_instances wi
|
|
JOIN proposals p ON p.id = wi.proposal_id
|
|
WHERE wi.id = v_workflow_instance_id;
|
|
|
|
-- Calculate eligible count based on scope
|
|
IF v_quorum_scope = 'community' THEN
|
|
SELECT COUNT(*) INTO eligible_count
|
|
FROM community_members
|
|
WHERE community_id = v_community_id;
|
|
ELSIF v_quorum_scope = 'participants' THEN
|
|
SELECT COUNT(DISTINCT user_id) INTO eligible_count
|
|
FROM phase_participation pp
|
|
JOIN phase_instances pi ON pi.id = pp.phase_instance_id
|
|
WHERE pi.workflow_instance_id = v_workflow_instance_id;
|
|
ELSE
|
|
SELECT COUNT(*) INTO eligible_count
|
|
FROM community_members
|
|
WHERE community_id = v_community_id;
|
|
END IF;
|
|
|
|
-- Get participant count for this phase
|
|
SELECT COUNT(DISTINCT user_id) INTO participant_count
|
|
FROM phase_participation
|
|
WHERE phase_instance_id = p_phase_instance_id;
|
|
|
|
-- Calculate quorum
|
|
IF v_quorum_type = 'percentage' THEN
|
|
quorum_required := v_quorum_value;
|
|
IF eligible_count > 0 THEN
|
|
quorum_current := participant_count::DECIMAL / eligible_count;
|
|
ELSE
|
|
quorum_current := 0;
|
|
END IF;
|
|
ELSIF v_quorum_type = 'absolute' THEN
|
|
quorum_required := v_quorum_value;
|
|
quorum_current := participant_count;
|
|
ELSE
|
|
quorum_required := v_quorum_value;
|
|
quorum_current := CASE WHEN eligible_count > 0
|
|
THEN participant_count::DECIMAL / eligible_count
|
|
ELSE 0 END;
|
|
END IF;
|
|
|
|
is_met := quorum_current >= quorum_required;
|
|
|
|
RETURN NEXT;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Advance workflow to next phase
|
|
CREATE OR REPLACE FUNCTION advance_workflow_phase(
|
|
p_workflow_instance_id UUID,
|
|
p_triggered_by VARCHAR(50) DEFAULT 'auto',
|
|
p_triggered_by_user_id UUID DEFAULT NULL,
|
|
p_reason TEXT DEFAULT NULL
|
|
) RETURNS UUID AS $$
|
|
DECLARE
|
|
v_current_phase_id UUID;
|
|
v_next_phase_id UUID;
|
|
v_current_phase_instance_id UUID;
|
|
v_new_phase_instance_id UUID;
|
|
v_phase_config workflow_phases%ROWTYPE;
|
|
BEGIN
|
|
-- Get current phase
|
|
SELECT current_phase_id INTO v_current_phase_id
|
|
FROM workflow_instances
|
|
WHERE id = p_workflow_instance_id;
|
|
|
|
-- Get current phase instance
|
|
SELECT id INTO v_current_phase_instance_id
|
|
FROM phase_instances
|
|
WHERE workflow_instance_id = p_workflow_instance_id AND phase_id = v_current_phase_id;
|
|
|
|
-- Complete current phase
|
|
IF v_current_phase_instance_id IS NOT NULL THEN
|
|
UPDATE phase_instances
|
|
SET status = 'completed',
|
|
actual_end = NOW(),
|
|
completion_reason = p_triggered_by
|
|
WHERE id = v_current_phase_instance_id;
|
|
END IF;
|
|
|
|
-- Find next phase
|
|
SELECT wp.id INTO v_next_phase_id
|
|
FROM workflow_phases wp
|
|
JOIN workflow_instances wi ON wi.template_id = wp.template_id
|
|
WHERE wi.id = p_workflow_instance_id
|
|
AND wp.sequence_order > COALESCE(
|
|
(SELECT sequence_order FROM workflow_phases WHERE id = v_current_phase_id), -1
|
|
)
|
|
ORDER BY wp.sequence_order
|
|
LIMIT 1;
|
|
|
|
-- Log transition
|
|
INSERT INTO workflow_transitions (
|
|
workflow_instance_id, from_phase_id, to_phase_id,
|
|
transition_type, triggered_by, triggered_by_user_id, reason
|
|
) VALUES (
|
|
p_workflow_instance_id, v_current_phase_id, v_next_phase_id,
|
|
CASE WHEN v_next_phase_id IS NULL THEN 'complete' ELSE 'advance' END,
|
|
p_triggered_by, p_triggered_by_user_id, p_reason
|
|
);
|
|
|
|
IF v_next_phase_id IS NULL THEN
|
|
-- Workflow complete
|
|
UPDATE workflow_instances
|
|
SET status = 'completed',
|
|
current_phase_id = NULL,
|
|
completed_at = NOW()
|
|
WHERE id = p_workflow_instance_id;
|
|
RETURN NULL;
|
|
END IF;
|
|
|
|
-- Get next phase config
|
|
SELECT * INTO v_phase_config FROM workflow_phases WHERE id = v_next_phase_id;
|
|
|
|
-- Create new phase instance
|
|
INSERT INTO phase_instances (
|
|
workflow_instance_id, phase_id, status,
|
|
scheduled_start, actual_start, scheduled_end
|
|
) VALUES (
|
|
p_workflow_instance_id, v_next_phase_id, 'active',
|
|
NOW(), NOW(),
|
|
NOW() + (v_phase_config.default_duration_hours || ' hours')::INTERVAL
|
|
) RETURNING id INTO v_new_phase_instance_id;
|
|
|
|
-- Update workflow instance
|
|
UPDATE workflow_instances
|
|
SET current_phase_id = v_next_phase_id
|
|
WHERE id = p_workflow_instance_id;
|
|
|
|
RETURN v_new_phase_instance_id;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Start a workflow for a proposal
|
|
CREATE OR REPLACE FUNCTION start_workflow(
|
|
p_proposal_id UUID,
|
|
p_template_id UUID
|
|
) RETURNS UUID AS $$
|
|
DECLARE
|
|
v_workflow_instance_id UUID;
|
|
v_first_phase_id UUID;
|
|
v_phase_config workflow_phases%ROWTYPE;
|
|
BEGIN
|
|
-- Create workflow instance
|
|
INSERT INTO workflow_instances (proposal_id, template_id, status)
|
|
VALUES (p_proposal_id, p_template_id, 'active')
|
|
RETURNING id INTO v_workflow_instance_id;
|
|
|
|
-- Get first phase
|
|
SELECT id INTO v_first_phase_id
|
|
FROM workflow_phases
|
|
WHERE template_id = p_template_id
|
|
ORDER BY sequence_order
|
|
LIMIT 1;
|
|
|
|
IF v_first_phase_id IS NOT NULL THEN
|
|
SELECT * INTO v_phase_config FROM workflow_phases WHERE id = v_first_phase_id;
|
|
|
|
-- Create first phase instance
|
|
INSERT INTO phase_instances (
|
|
workflow_instance_id, phase_id, status,
|
|
scheduled_start, actual_start, scheduled_end
|
|
) VALUES (
|
|
v_workflow_instance_id, v_first_phase_id, 'active',
|
|
NOW(), NOW(),
|
|
NOW() + (v_phase_config.default_duration_hours || ' hours')::INTERVAL
|
|
);
|
|
|
|
-- Update workflow with current phase
|
|
UPDATE workflow_instances
|
|
SET current_phase_id = v_first_phase_id
|
|
WHERE id = v_workflow_instance_id;
|
|
END IF;
|
|
|
|
RETURN v_workflow_instance_id;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- ============================================================================
|
|
-- DEFAULT WORKFLOW TEMPLATES
|
|
-- ============================================================================
|
|
|
|
-- Standard governance workflow
|
|
INSERT INTO workflow_templates (id, community_id, name, description, is_system, config)
|
|
VALUES (
|
|
'a0000000-0000-0000-0000-000000000001'::UUID,
|
|
NULL, -- Global template
|
|
'Standard Governance',
|
|
'Standard 4-phase governance workflow: Discussion → Amendment → Vote → Ratification',
|
|
true,
|
|
jsonb_build_object(
|
|
'allow_skip_phases', false,
|
|
'require_all_phases', true,
|
|
'notify_on_transition', true
|
|
)
|
|
);
|
|
|
|
-- Insert phases for standard workflow
|
|
INSERT INTO workflow_phases (template_id, name, phase_type, sequence_order, description, default_duration_hours, quorum_value, phase_config)
|
|
VALUES
|
|
('a0000000-0000-0000-0000-000000000001'::UUID, 'Discussion', 'discussion', 1,
|
|
'Open discussion period for community input', 168, 0.05,
|
|
'{"allow_amendments": false, "min_comments": 3}'::JSONB),
|
|
('a0000000-0000-0000-0000-000000000001'::UUID, 'Amendment', 'amendment', 2,
|
|
'Proposal refinement based on feedback', 72, 0.03,
|
|
'{"allow_amendments": true, "require_author_approval": true}'::JSONB),
|
|
('a0000000-0000-0000-0000-000000000001'::UUID, 'Voting', 'vote', 3,
|
|
'Community voting on the proposal', 168, 0.15,
|
|
'{"voting_method": "schulze", "allow_abstain": true}'::JSONB),
|
|
('a0000000-0000-0000-0000-000000000001'::UUID, 'Ratification', 'ratification', 4,
|
|
'Final ratification and implementation planning', 48, 0.10,
|
|
'{"require_implementation_plan": true}'::JSONB);
|
|
|
|
-- Quick decision workflow
|
|
INSERT INTO workflow_templates (id, community_id, name, description, is_system, config)
|
|
VALUES (
|
|
'a0000000-0000-0000-0000-000000000002'::UUID,
|
|
NULL,
|
|
'Quick Decision',
|
|
'Expedited 2-phase workflow for time-sensitive decisions',
|
|
true,
|
|
jsonb_build_object(
|
|
'allow_skip_phases', true,
|
|
'max_duration_hours', 72
|
|
)
|
|
);
|
|
|
|
INSERT INTO workflow_phases (template_id, name, phase_type, sequence_order, description, default_duration_hours, quorum_value, allow_early_completion)
|
|
VALUES
|
|
('a0000000-0000-0000-0000-000000000002'::UUID, 'Discussion & Review', 'discussion', 1,
|
|
'Combined discussion and review period', 24, 0.10, true),
|
|
('a0000000-0000-0000-0000-000000000002'::UUID, 'Voting', 'vote', 2,
|
|
'Community voting', 48, 0.20, true);
|
|
|
|
-- Consensus-seeking workflow
|
|
INSERT INTO workflow_templates (id, community_id, name, description, is_system, config)
|
|
VALUES (
|
|
'a0000000-0000-0000-0000-000000000003'::UUID,
|
|
NULL,
|
|
'Consensus Building',
|
|
'Extended workflow focused on achieving broad consensus',
|
|
true,
|
|
jsonb_build_object(
|
|
'consensus_threshold', 0.75,
|
|
'allow_multiple_rounds', true
|
|
)
|
|
);
|
|
|
|
INSERT INTO workflow_phases (template_id, name, phase_type, sequence_order, description, default_duration_hours, quorum_value, require_comment)
|
|
VALUES
|
|
('a0000000-0000-0000-0000-000000000003'::UUID, 'Initial Discussion', 'discussion', 1,
|
|
'Gather initial perspectives', 168, 0.10, false),
|
|
('a0000000-0000-0000-0000-000000000003'::UUID, 'Synthesis', 'amendment', 2,
|
|
'Synthesize feedback into revised proposal', 72, 0.05, true),
|
|
('a0000000-0000-0000-0000-000000000003'::UUID, 'Consensus Check', 'vote', 3,
|
|
'Check for consensus (75% threshold)', 72, 0.25, false),
|
|
('a0000000-0000-0000-0000-000000000003'::UUID, 'Final Adjustments', 'amendment', 4,
|
|
'Address remaining concerns', 48, 0.05, true),
|
|
('a0000000-0000-0000-0000-000000000003'::UUID, 'Final Vote', 'vote', 5,
|
|
'Final community decision', 168, 0.30, false);
|
|
|
|
-- ============================================================================
|
|
-- VIEWS
|
|
-- ============================================================================
|
|
|
|
CREATE OR REPLACE VIEW active_workflows AS
|
|
SELECT
|
|
wi.id AS workflow_instance_id,
|
|
wi.proposal_id,
|
|
p.title AS proposal_title,
|
|
wt.name AS workflow_name,
|
|
wp.name AS current_phase_name,
|
|
wp.phase_type AS current_phase_type,
|
|
pi.scheduled_end AS phase_deadline,
|
|
pi.participant_count,
|
|
pi.quorum_reached,
|
|
wi.started_at,
|
|
wi.status
|
|
FROM workflow_instances wi
|
|
JOIN proposals p ON p.id = wi.proposal_id
|
|
JOIN workflow_templates wt ON wt.id = wi.template_id
|
|
LEFT JOIN workflow_phases wp ON wp.id = wi.current_phase_id
|
|
LEFT JOIN phase_instances pi ON pi.workflow_instance_id = wi.id AND pi.phase_id = wi.current_phase_id
|
|
WHERE wi.status = 'active';
|
|
|
|
CREATE OR REPLACE VIEW workflow_progress AS
|
|
SELECT
|
|
wi.id AS workflow_instance_id,
|
|
wi.proposal_id,
|
|
wt.name AS workflow_name,
|
|
COUNT(wp.id) AS total_phases,
|
|
COUNT(pi.id) FILTER (WHERE pi.status = 'completed') AS completed_phases,
|
|
ROUND(
|
|
COUNT(pi.id) FILTER (WHERE pi.status = 'completed')::DECIMAL /
|
|
NULLIF(COUNT(wp.id), 0) * 100, 1
|
|
) AS progress_percentage
|
|
FROM workflow_instances wi
|
|
JOIN workflow_templates wt ON wt.id = wi.template_id
|
|
JOIN workflow_phases wp ON wp.template_id = wt.id
|
|
LEFT JOIN phase_instances pi ON pi.workflow_instance_id = wi.id AND pi.phase_id = wp.id
|
|
GROUP BY wi.id, wi.proposal_id, wt.name;
|
|
|
|
-- ============================================================================
|
|
-- PLUGIN REGISTRATION
|
|
-- ============================================================================
|
|
|
|
INSERT INTO plugins (name, description, version, is_core, is_active, settings_schema)
|
|
VALUES (
|
|
'decision_workflows',
|
|
'Composable decision-making workflows with configurable phases, timeouts, and quorum requirements. Foundation for all governance processes.',
|
|
'1.0.0',
|
|
true,
|
|
true,
|
|
jsonb_build_object(
|
|
'type', 'object',
|
|
'properties', jsonb_build_object(
|
|
'default_workflow', jsonb_build_object(
|
|
'type', 'string',
|
|
'title', 'Default Workflow',
|
|
'description', 'Default workflow template for new proposals',
|
|
'default', 'Standard Governance'
|
|
),
|
|
'allow_custom_workflows', jsonb_build_object(
|
|
'type', 'boolean',
|
|
'title', 'Allow Custom Workflows',
|
|
'description', 'Allow communities to create custom workflow templates',
|
|
'default', true
|
|
),
|
|
'auto_advance_phases', jsonb_build_object(
|
|
'type', 'boolean',
|
|
'title', 'Auto-advance Phases',
|
|
'description', 'Automatically advance to next phase when conditions are met',
|
|
'default', true
|
|
),
|
|
'quorum_check_interval_minutes', jsonb_build_object(
|
|
'type', 'integer',
|
|
'title', 'Quorum Check Interval',
|
|
'description', 'How often to check and record quorum status (minutes)',
|
|
'default', 60,
|
|
'minimum', 5,
|
|
'maximum', 1440
|
|
)
|
|
)
|
|
)
|
|
) ON CONFLICT (name) DO UPDATE SET
|
|
version = EXCLUDED.version,
|
|
description = EXCLUDED.description;
|