Reformatted multiline function calls, object definitions, and queries for improved code readability and consistency. Adjusted imports and constraints where necessary.
508 lines
19 KiB
Python
508 lines
19 KiB
Python
"""Add Syndarix models
|
|
|
|
Revision ID: 0004
|
|
Revises: 0003
|
|
Create Date: 2025-12-31
|
|
|
|
This migration creates the core Syndarix domain tables:
|
|
- projects: Client engagement projects
|
|
- agent_types: Agent template configurations
|
|
- agent_instances: Spawned agent instances assigned to projects
|
|
- sprints: Sprint containers for issues
|
|
- issues: Work items (epics, stories, tasks, bugs)
|
|
"""
|
|
|
|
from collections.abc import Sequence
|
|
|
|
import sqlalchemy as sa
|
|
from alembic import op
|
|
from sqlalchemy.dialects import postgresql
|
|
|
|
# revision identifiers, used by Alembic.
|
|
revision: str = "0004"
|
|
down_revision: str | None = "0003"
|
|
branch_labels: str | Sequence[str] | None = None
|
|
depends_on: str | Sequence[str] | None = None
|
|
|
|
|
|
def upgrade() -> None:
|
|
"""Create Syndarix domain tables."""
|
|
|
|
# =========================================================================
|
|
# Create projects table
|
|
# Note: ENUM types are created automatically by sa.Enum() during table creation
|
|
# =========================================================================
|
|
op.create_table(
|
|
"projects",
|
|
sa.Column("id", postgresql.UUID(as_uuid=True), nullable=False),
|
|
sa.Column("name", sa.String(255), nullable=False),
|
|
sa.Column("slug", sa.String(255), nullable=False),
|
|
sa.Column("description", sa.Text(), nullable=True),
|
|
sa.Column(
|
|
"autonomy_level",
|
|
sa.Enum(
|
|
"full_control",
|
|
"milestone",
|
|
"autonomous",
|
|
name="autonomy_level",
|
|
),
|
|
nullable=False,
|
|
server_default="milestone",
|
|
),
|
|
sa.Column(
|
|
"status",
|
|
sa.Enum(
|
|
"active",
|
|
"paused",
|
|
"completed",
|
|
"archived",
|
|
name="project_status",
|
|
),
|
|
nullable=False,
|
|
server_default="active",
|
|
),
|
|
sa.Column(
|
|
"complexity",
|
|
sa.Enum(
|
|
"script",
|
|
"simple",
|
|
"medium",
|
|
"complex",
|
|
name="project_complexity",
|
|
),
|
|
nullable=False,
|
|
server_default="medium",
|
|
),
|
|
sa.Column(
|
|
"client_mode",
|
|
sa.Enum("technical", "auto", name="client_mode"),
|
|
nullable=False,
|
|
server_default="auto",
|
|
),
|
|
sa.Column(
|
|
"settings",
|
|
postgresql.JSONB(astext_type=sa.Text()),
|
|
nullable=False,
|
|
server_default="{}",
|
|
),
|
|
sa.Column("owner_id", postgresql.UUID(as_uuid=True), nullable=True),
|
|
sa.Column(
|
|
"created_at",
|
|
sa.DateTime(timezone=True),
|
|
nullable=False,
|
|
server_default=sa.text("now()"),
|
|
),
|
|
sa.Column(
|
|
"updated_at",
|
|
sa.DateTime(timezone=True),
|
|
nullable=False,
|
|
server_default=sa.text("now()"),
|
|
),
|
|
sa.PrimaryKeyConstraint("id"),
|
|
sa.ForeignKeyConstraint(["owner_id"], ["users.id"], ondelete="SET NULL"),
|
|
sa.UniqueConstraint("slug"),
|
|
)
|
|
# Single column indexes
|
|
op.create_index("ix_projects_name", "projects", ["name"])
|
|
op.create_index("ix_projects_slug", "projects", ["slug"])
|
|
op.create_index("ix_projects_status", "projects", ["status"])
|
|
op.create_index("ix_projects_autonomy_level", "projects", ["autonomy_level"])
|
|
op.create_index("ix_projects_complexity", "projects", ["complexity"])
|
|
op.create_index("ix_projects_client_mode", "projects", ["client_mode"])
|
|
op.create_index("ix_projects_owner_id", "projects", ["owner_id"])
|
|
# Composite indexes
|
|
op.create_index("ix_projects_slug_status", "projects", ["slug", "status"])
|
|
op.create_index("ix_projects_owner_status", "projects", ["owner_id", "status"])
|
|
op.create_index(
|
|
"ix_projects_autonomy_status", "projects", ["autonomy_level", "status"]
|
|
)
|
|
op.create_index(
|
|
"ix_projects_complexity_status", "projects", ["complexity", "status"]
|
|
)
|
|
|
|
# =========================================================================
|
|
# Create agent_types table
|
|
# =========================================================================
|
|
op.create_table(
|
|
"agent_types",
|
|
sa.Column("id", postgresql.UUID(as_uuid=True), nullable=False),
|
|
sa.Column("name", sa.String(255), nullable=False),
|
|
sa.Column("slug", sa.String(255), nullable=False),
|
|
sa.Column("description", sa.Text(), nullable=True),
|
|
# Areas of expertise (e.g., ["python", "fastapi", "databases"])
|
|
sa.Column(
|
|
"expertise",
|
|
postgresql.JSONB(astext_type=sa.Text()),
|
|
nullable=False,
|
|
server_default="[]",
|
|
),
|
|
# System prompt defining personality and behavior (required)
|
|
sa.Column("personality_prompt", sa.Text(), nullable=False),
|
|
# LLM model configuration
|
|
sa.Column("primary_model", sa.String(100), nullable=False),
|
|
sa.Column(
|
|
"fallback_models",
|
|
postgresql.JSONB(astext_type=sa.Text()),
|
|
nullable=False,
|
|
server_default="[]",
|
|
),
|
|
# Model parameters (temperature, max_tokens, etc.)
|
|
sa.Column(
|
|
"model_params",
|
|
postgresql.JSONB(astext_type=sa.Text()),
|
|
nullable=False,
|
|
server_default="{}",
|
|
),
|
|
# MCP servers this agent can connect to
|
|
sa.Column(
|
|
"mcp_servers",
|
|
postgresql.JSONB(astext_type=sa.Text()),
|
|
nullable=False,
|
|
server_default="[]",
|
|
),
|
|
# Tool permissions configuration
|
|
sa.Column(
|
|
"tool_permissions",
|
|
postgresql.JSONB(astext_type=sa.Text()),
|
|
nullable=False,
|
|
server_default="{}",
|
|
),
|
|
sa.Column("is_active", sa.Boolean(), nullable=False, server_default="true"),
|
|
sa.Column(
|
|
"created_at",
|
|
sa.DateTime(timezone=True),
|
|
nullable=False,
|
|
server_default=sa.text("now()"),
|
|
),
|
|
sa.Column(
|
|
"updated_at",
|
|
sa.DateTime(timezone=True),
|
|
nullable=False,
|
|
server_default=sa.text("now()"),
|
|
),
|
|
sa.PrimaryKeyConstraint("id"),
|
|
sa.UniqueConstraint("slug"),
|
|
)
|
|
# Single column indexes
|
|
op.create_index("ix_agent_types_name", "agent_types", ["name"])
|
|
op.create_index("ix_agent_types_slug", "agent_types", ["slug"])
|
|
op.create_index("ix_agent_types_is_active", "agent_types", ["is_active"])
|
|
# Composite indexes
|
|
op.create_index("ix_agent_types_slug_active", "agent_types", ["slug", "is_active"])
|
|
op.create_index("ix_agent_types_name_active", "agent_types", ["name", "is_active"])
|
|
|
|
# =========================================================================
|
|
# Create agent_instances table
|
|
# =========================================================================
|
|
op.create_table(
|
|
"agent_instances",
|
|
sa.Column("id", postgresql.UUID(as_uuid=True), nullable=False),
|
|
sa.Column("agent_type_id", postgresql.UUID(as_uuid=True), nullable=False),
|
|
sa.Column("project_id", postgresql.UUID(as_uuid=True), nullable=False),
|
|
sa.Column("name", sa.String(100), nullable=False),
|
|
sa.Column(
|
|
"status",
|
|
sa.Enum(
|
|
"idle",
|
|
"working",
|
|
"waiting",
|
|
"paused",
|
|
"terminated",
|
|
name="agent_status",
|
|
),
|
|
nullable=False,
|
|
server_default="idle",
|
|
),
|
|
sa.Column("current_task", sa.Text(), nullable=True),
|
|
# Short-term memory (conversation context, recent decisions)
|
|
sa.Column(
|
|
"short_term_memory",
|
|
postgresql.JSONB(astext_type=sa.Text()),
|
|
nullable=False,
|
|
server_default="{}",
|
|
),
|
|
# Reference to long-term memory in vector store
|
|
sa.Column("long_term_memory_ref", sa.String(500), nullable=True),
|
|
# Session ID for active MCP connections
|
|
sa.Column("session_id", sa.String(255), nullable=True),
|
|
# Activity tracking
|
|
sa.Column("last_activity_at", sa.DateTime(timezone=True), nullable=True),
|
|
sa.Column("terminated_at", sa.DateTime(timezone=True), nullable=True),
|
|
# Usage metrics
|
|
sa.Column("tasks_completed", sa.Integer(), nullable=False, server_default="0"),
|
|
sa.Column("tokens_used", sa.BigInteger(), nullable=False, server_default="0"),
|
|
sa.Column(
|
|
"cost_incurred",
|
|
sa.Numeric(precision=10, scale=4),
|
|
nullable=False,
|
|
server_default="0",
|
|
),
|
|
sa.Column(
|
|
"created_at",
|
|
sa.DateTime(timezone=True),
|
|
nullable=False,
|
|
server_default=sa.text("now()"),
|
|
),
|
|
sa.Column(
|
|
"updated_at",
|
|
sa.DateTime(timezone=True),
|
|
nullable=False,
|
|
server_default=sa.text("now()"),
|
|
),
|
|
sa.PrimaryKeyConstraint("id"),
|
|
sa.ForeignKeyConstraint(
|
|
["agent_type_id"], ["agent_types.id"], ondelete="RESTRICT"
|
|
),
|
|
sa.ForeignKeyConstraint(["project_id"], ["projects.id"], ondelete="CASCADE"),
|
|
)
|
|
# Single column indexes
|
|
op.create_index("ix_agent_instances_name", "agent_instances", ["name"])
|
|
op.create_index("ix_agent_instances_status", "agent_instances", ["status"])
|
|
op.create_index(
|
|
"ix_agent_instances_agent_type_id", "agent_instances", ["agent_type_id"]
|
|
)
|
|
op.create_index("ix_agent_instances_project_id", "agent_instances", ["project_id"])
|
|
op.create_index("ix_agent_instances_session_id", "agent_instances", ["session_id"])
|
|
op.create_index(
|
|
"ix_agent_instances_last_activity_at", "agent_instances", ["last_activity_at"]
|
|
)
|
|
op.create_index(
|
|
"ix_agent_instances_terminated_at", "agent_instances", ["terminated_at"]
|
|
)
|
|
# Composite indexes
|
|
op.create_index(
|
|
"ix_agent_instances_project_status",
|
|
"agent_instances",
|
|
["project_id", "status"],
|
|
)
|
|
op.create_index(
|
|
"ix_agent_instances_type_status",
|
|
"agent_instances",
|
|
["agent_type_id", "status"],
|
|
)
|
|
op.create_index(
|
|
"ix_agent_instances_project_type",
|
|
"agent_instances",
|
|
["project_id", "agent_type_id"],
|
|
)
|
|
|
|
# =========================================================================
|
|
# Create sprints table (before issues for FK reference)
|
|
# =========================================================================
|
|
op.create_table(
|
|
"sprints",
|
|
sa.Column("id", postgresql.UUID(as_uuid=True), nullable=False),
|
|
sa.Column("project_id", postgresql.UUID(as_uuid=True), nullable=False),
|
|
sa.Column("name", sa.String(255), nullable=False),
|
|
sa.Column("number", sa.Integer(), nullable=False),
|
|
sa.Column("goal", sa.Text(), nullable=True),
|
|
sa.Column("start_date", sa.Date(), nullable=False),
|
|
sa.Column("end_date", sa.Date(), nullable=False),
|
|
sa.Column(
|
|
"status",
|
|
sa.Enum(
|
|
"planned",
|
|
"active",
|
|
"in_review",
|
|
"completed",
|
|
"cancelled",
|
|
name="sprint_status",
|
|
),
|
|
nullable=False,
|
|
server_default="planned",
|
|
),
|
|
sa.Column("planned_points", sa.Integer(), nullable=True),
|
|
sa.Column("velocity", sa.Integer(), nullable=True),
|
|
sa.Column(
|
|
"created_at",
|
|
sa.DateTime(timezone=True),
|
|
nullable=False,
|
|
server_default=sa.text("now()"),
|
|
),
|
|
sa.Column(
|
|
"updated_at",
|
|
sa.DateTime(timezone=True),
|
|
nullable=False,
|
|
server_default=sa.text("now()"),
|
|
),
|
|
sa.PrimaryKeyConstraint("id"),
|
|
sa.ForeignKeyConstraint(["project_id"], ["projects.id"], ondelete="CASCADE"),
|
|
sa.UniqueConstraint("project_id", "number", name="uq_sprint_project_number"),
|
|
)
|
|
# Single column indexes
|
|
op.create_index("ix_sprints_project_id", "sprints", ["project_id"])
|
|
op.create_index("ix_sprints_status", "sprints", ["status"])
|
|
op.create_index("ix_sprints_start_date", "sprints", ["start_date"])
|
|
op.create_index("ix_sprints_end_date", "sprints", ["end_date"])
|
|
# Composite indexes
|
|
op.create_index("ix_sprints_project_status", "sprints", ["project_id", "status"])
|
|
op.create_index("ix_sprints_project_number", "sprints", ["project_id", "number"])
|
|
op.create_index("ix_sprints_date_range", "sprints", ["start_date", "end_date"])
|
|
|
|
# =========================================================================
|
|
# Create issues table
|
|
# =========================================================================
|
|
op.create_table(
|
|
"issues",
|
|
sa.Column("id", postgresql.UUID(as_uuid=True), nullable=False),
|
|
sa.Column("project_id", postgresql.UUID(as_uuid=True), nullable=False),
|
|
# Parent issue for hierarchy (Epic -> Story -> Task)
|
|
sa.Column("parent_id", postgresql.UUID(as_uuid=True), nullable=True),
|
|
# Issue type (epic, story, task, bug)
|
|
sa.Column(
|
|
"type",
|
|
sa.Enum(
|
|
"epic",
|
|
"story",
|
|
"task",
|
|
"bug",
|
|
name="issue_type",
|
|
),
|
|
nullable=False,
|
|
server_default="task",
|
|
),
|
|
# Reporter (who created this issue)
|
|
sa.Column("reporter_id", postgresql.UUID(as_uuid=True), nullable=True),
|
|
# Issue content
|
|
sa.Column("title", sa.String(500), nullable=False),
|
|
sa.Column("body", sa.Text(), nullable=False, server_default=""),
|
|
# Status and priority
|
|
sa.Column(
|
|
"status",
|
|
sa.Enum(
|
|
"open",
|
|
"in_progress",
|
|
"in_review",
|
|
"blocked",
|
|
"closed",
|
|
name="issue_status",
|
|
),
|
|
nullable=False,
|
|
server_default="open",
|
|
),
|
|
sa.Column(
|
|
"priority",
|
|
sa.Enum(
|
|
"low",
|
|
"medium",
|
|
"high",
|
|
"critical",
|
|
name="issue_priority",
|
|
),
|
|
nullable=False,
|
|
server_default="medium",
|
|
),
|
|
# Labels for categorization
|
|
sa.Column(
|
|
"labels",
|
|
postgresql.JSONB(astext_type=sa.Text()),
|
|
nullable=False,
|
|
server_default="[]",
|
|
),
|
|
# Assignment - agent or human (mutually exclusive)
|
|
sa.Column("assigned_agent_id", postgresql.UUID(as_uuid=True), nullable=True),
|
|
sa.Column("human_assignee", sa.String(255), nullable=True),
|
|
# Sprint association
|
|
sa.Column("sprint_id", postgresql.UUID(as_uuid=True), nullable=True),
|
|
# Estimation
|
|
sa.Column("story_points", sa.Integer(), nullable=True),
|
|
sa.Column("due_date", sa.Date(), nullable=True),
|
|
# External tracker integration (String for flexibility)
|
|
sa.Column("external_tracker_type", sa.String(50), nullable=True),
|
|
sa.Column("external_issue_id", sa.String(255), nullable=True),
|
|
sa.Column("remote_url", sa.String(1000), nullable=True),
|
|
sa.Column("external_issue_number", sa.Integer(), nullable=True),
|
|
# Sync status
|
|
sa.Column(
|
|
"sync_status",
|
|
sa.Enum(
|
|
"synced",
|
|
"pending",
|
|
"conflict",
|
|
"error",
|
|
name="sync_status",
|
|
),
|
|
nullable=False,
|
|
server_default="synced",
|
|
),
|
|
sa.Column("last_synced_at", sa.DateTime(timezone=True), nullable=True),
|
|
sa.Column("external_updated_at", sa.DateTime(timezone=True), nullable=True),
|
|
# Lifecycle
|
|
sa.Column("closed_at", sa.DateTime(timezone=True), nullable=True),
|
|
sa.Column(
|
|
"created_at",
|
|
sa.DateTime(timezone=True),
|
|
nullable=False,
|
|
server_default=sa.text("now()"),
|
|
),
|
|
sa.Column(
|
|
"updated_at",
|
|
sa.DateTime(timezone=True),
|
|
nullable=False,
|
|
server_default=sa.text("now()"),
|
|
),
|
|
sa.PrimaryKeyConstraint("id"),
|
|
sa.ForeignKeyConstraint(["project_id"], ["projects.id"], ondelete="CASCADE"),
|
|
sa.ForeignKeyConstraint(["parent_id"], ["issues.id"], ondelete="CASCADE"),
|
|
sa.ForeignKeyConstraint(["sprint_id"], ["sprints.id"], ondelete="SET NULL"),
|
|
sa.ForeignKeyConstraint(
|
|
["assigned_agent_id"], ["agent_instances.id"], ondelete="SET NULL"
|
|
),
|
|
)
|
|
# Single column indexes
|
|
op.create_index("ix_issues_project_id", "issues", ["project_id"])
|
|
op.create_index("ix_issues_parent_id", "issues", ["parent_id"])
|
|
op.create_index("ix_issues_type", "issues", ["type"])
|
|
op.create_index("ix_issues_reporter_id", "issues", ["reporter_id"])
|
|
op.create_index("ix_issues_status", "issues", ["status"])
|
|
op.create_index("ix_issues_priority", "issues", ["priority"])
|
|
op.create_index("ix_issues_assigned_agent_id", "issues", ["assigned_agent_id"])
|
|
op.create_index("ix_issues_human_assignee", "issues", ["human_assignee"])
|
|
op.create_index("ix_issues_sprint_id", "issues", ["sprint_id"])
|
|
op.create_index("ix_issues_due_date", "issues", ["due_date"])
|
|
op.create_index(
|
|
"ix_issues_external_tracker_type", "issues", ["external_tracker_type"]
|
|
)
|
|
op.create_index("ix_issues_sync_status", "issues", ["sync_status"])
|
|
op.create_index("ix_issues_closed_at", "issues", ["closed_at"])
|
|
# Composite indexes
|
|
op.create_index("ix_issues_project_status", "issues", ["project_id", "status"])
|
|
op.create_index("ix_issues_project_priority", "issues", ["project_id", "priority"])
|
|
op.create_index("ix_issues_project_sprint", "issues", ["project_id", "sprint_id"])
|
|
op.create_index("ix_issues_project_type", "issues", ["project_id", "type"])
|
|
op.create_index(
|
|
"ix_issues_project_agent", "issues", ["project_id", "assigned_agent_id"]
|
|
)
|
|
op.create_index(
|
|
"ix_issues_project_status_priority",
|
|
"issues",
|
|
["project_id", "status", "priority"],
|
|
)
|
|
op.create_index(
|
|
"ix_issues_external_tracker_id",
|
|
"issues",
|
|
["external_tracker_type", "external_issue_id"],
|
|
)
|
|
|
|
|
|
def downgrade() -> None:
|
|
"""Drop Syndarix domain tables."""
|
|
# Drop tables in reverse order (respecting FK constraints)
|
|
op.drop_table("issues")
|
|
op.drop_table("sprints")
|
|
op.drop_table("agent_instances")
|
|
op.drop_table("agent_types")
|
|
op.drop_table("projects")
|
|
|
|
# Drop ENUM types
|
|
op.execute("DROP TYPE IF EXISTS sprint_status")
|
|
op.execute("DROP TYPE IF EXISTS sync_status")
|
|
op.execute("DROP TYPE IF EXISTS issue_priority")
|
|
op.execute("DROP TYPE IF EXISTS issue_status")
|
|
op.execute("DROP TYPE IF EXISTS issue_type")
|
|
op.execute("DROP TYPE IF EXISTS agent_status")
|
|
op.execute("DROP TYPE IF EXISTS client_mode")
|
|
op.execute("DROP TYPE IF EXISTS project_complexity")
|
|
op.execute("DROP TYPE IF EXISTS project_status")
|
|
op.execute("DROP TYPE IF EXISTS autonomy_level")
|