-- Add council-related tables for project kickoff management -- Councils table: tracks project kickoff councils CREATE TABLE IF NOT EXISTS councils ( id UUID PRIMARY KEY, project_name VARCHAR(255) NOT NULL, repository VARCHAR(500) NOT NULL, project_brief TEXT NOT NULL, constraints TEXT, tech_limits TEXT, compliance_notes TEXT, targets TEXT, status VARCHAR(50) NOT NULL DEFAULT 'forming', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), completed_at TIMESTAMPTZ, -- Link to original task/issue task_id UUID REFERENCES tasks(id) ON DELETE SET NULL, issue_id BIGINT, external_url TEXT, -- Additional metadata metadata JSONB, -- Indexes CONSTRAINT councils_status_check CHECK (status IN ('forming', 'active', 'completed', 'failed')) ); -- Council agents table: tracks individual agents in each council CREATE TABLE IF NOT EXISTS council_agents ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), council_id UUID NOT NULL REFERENCES councils(id) ON DELETE CASCADE, agent_id VARCHAR(255) NOT NULL, role_name VARCHAR(100) NOT NULL, agent_name VARCHAR(255) NOT NULL, required BOOLEAN NOT NULL DEFAULT true, deployed BOOLEAN NOT NULL DEFAULT false, status VARCHAR(50) NOT NULL DEFAULT 'pending', service_id VARCHAR(255), -- Docker Swarm service ID deployed_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Unique constraint to prevent duplicate agents in the same council UNIQUE(council_id, role_name), -- Status constraint CONSTRAINT council_agents_status_check CHECK (status IN ('pending', 'deploying', 'active', 'failed', 'removed')) ); -- Council artifacts table: tracks outputs produced by councils CREATE TABLE IF NOT EXISTS council_artifacts ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), council_id UUID NOT NULL REFERENCES councils(id) ON DELETE CASCADE, artifact_type VARCHAR(50) NOT NULL, artifact_name VARCHAR(255) NOT NULL, content TEXT, content_json JSONB, produced_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), produced_by VARCHAR(255), -- Which agent/role produced this status VARCHAR(50) NOT NULL DEFAULT 'draft', -- Artifact types: kickoff_manifest, seminal_dr, scaffold_plan, gate_tests, etc. CONSTRAINT council_artifacts_type_check CHECK (artifact_type IN ('kickoff_manifest', 'seminal_dr', 'scaffold_plan', 'gate_tests', 'hmmm_thread', 'slurp_sources', 'shhh_policy', 'ucxl_root')), CONSTRAINT council_artifacts_status_check CHECK (status IN ('draft', 'review', 'approved', 'rejected')) ); -- Council decisions table: tracks decision-making process CREATE TABLE IF NOT EXISTS council_decisions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), council_id UUID NOT NULL REFERENCES councils(id) ON DELETE CASCADE, decision_type VARCHAR(50) NOT NULL, decision_title VARCHAR(255) NOT NULL, context TEXT, options JSONB, -- Array of decision options with pros/cons chosen_option JSONB, rationale TEXT, consequences TEXT, reversibility VARCHAR(20), votes JSONB, -- Voting record by role dissent JSONB, -- Dissenting opinions decided_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), CONSTRAINT council_decisions_reversibility_check CHECK (reversibility IN ('high', 'medium', 'low', 'irreversible')) ); -- Indexes for performance CREATE INDEX IF NOT EXISTS idx_councils_status ON councils(status); CREATE INDEX IF NOT EXISTS idx_councils_created_at ON councils(created_at); CREATE INDEX IF NOT EXISTS idx_councils_task_id ON councils(task_id); CREATE INDEX IF NOT EXISTS idx_councils_repository ON councils(repository); CREATE INDEX IF NOT EXISTS idx_council_agents_council_id ON council_agents(council_id); CREATE INDEX IF NOT EXISTS idx_council_agents_status ON council_agents(status); CREATE INDEX IF NOT EXISTS idx_council_agents_role_name ON council_agents(role_name); CREATE INDEX IF NOT EXISTS idx_council_agents_deployed ON council_agents(deployed); CREATE INDEX IF NOT EXISTS idx_council_artifacts_council_id ON council_artifacts(council_id); CREATE INDEX IF NOT EXISTS idx_council_artifacts_type ON council_artifacts(artifact_type); CREATE INDEX IF NOT EXISTS idx_council_artifacts_status ON council_artifacts(status); CREATE INDEX IF NOT EXISTS idx_council_decisions_council_id ON council_decisions(council_id); CREATE INDEX IF NOT EXISTS idx_council_decisions_type ON council_decisions(decision_type); -- Update timestamp triggers CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER update_councils_updated_at BEFORE UPDATE ON councils FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_council_agents_updated_at BEFORE UPDATE ON council_agents FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();