# Modelo de Datos (MySQL) ## Diagrama ER ``` ┌─────────────┐ ┌─────────────┐ ┌─────────────┐ │ Projects │───────│ Tasks │───────│ Agents │ └─────────────┘ 1:N └─────────────┘ N:1 └─────────────┘ │ 1:N │ ┌────▼────────┐ │ Questions │ └─────────────┘ ┌─────────────┐ ┌─────────────┐ │ TaskGroups │───────│ Deploys │ └─────────────┘ 1:N └─────────────┘ ``` ## Schema SQL ### Tabla: projects ```sql CREATE TABLE projects ( id VARCHAR(36) PRIMARY KEY, name VARCHAR(255) NOT NULL, description TEXT, -- Gitea integration gitea_repo_id INT, gitea_repo_url VARCHAR(512), gitea_owner VARCHAR(100), gitea_repo_name VARCHAR(100), default_branch VARCHAR(100) DEFAULT 'main', -- Kubernetes k8s_namespace VARCHAR(63) NOT NULL UNIQUE, -- Infrastructure config (JSON) docker_image VARCHAR(512), env_vars JSON, replicas INT DEFAULT 1, cpu_limit VARCHAR(20) DEFAULT '500m', memory_limit VARCHAR(20) DEFAULT '512Mi', -- MCP config (JSON) mcp_tools JSON, mcp_permissions JSON, -- Status status ENUM('active', 'paused', 'archived') DEFAULT 'active', -- Timestamps created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, INDEX idx_status (status), INDEX idx_k8s_namespace (k8s_namespace) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; ``` ### Tabla: tasks ```sql CREATE TABLE tasks ( id VARCHAR(36) PRIMARY KEY, project_id VARCHAR(36) NOT NULL, -- Task info title VARCHAR(255) NOT NULL, description TEXT, priority ENUM('low', 'medium', 'high', 'urgent') DEFAULT 'medium', -- State machine state ENUM( 'backlog', 'in_progress', 'needs_input', 'ready_to_test', 'approved', 'staging', 'production', 'cancelled' ) DEFAULT 'backlog', -- Assignment assigned_agent_id VARCHAR(36), assigned_at TIMESTAMP NULL, -- Git info branch_name VARCHAR(255), pr_number INT, pr_url VARCHAR(512), -- Preview deployment preview_namespace VARCHAR(63), preview_url VARCHAR(512), preview_deployed_at TIMESTAMP NULL, -- Metadata estimated_complexity ENUM('trivial', 'simple', 'medium', 'complex') DEFAULT 'medium', actual_duration_minutes INT, -- Timestamps created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, started_at TIMESTAMP NULL, completed_at TIMESTAMP NULL, deployed_staging_at TIMESTAMP NULL, deployed_production_at TIMESTAMP NULL, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE, FOREIGN KEY (assigned_agent_id) REFERENCES agents(id) ON DELETE SET NULL, INDEX idx_project_state (project_id, state), INDEX idx_state (state), INDEX idx_assigned_agent (assigned_agent_id), INDEX idx_created_at (created_at) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; ``` ### Tabla: task_questions ```sql CREATE TABLE task_questions ( id VARCHAR(36) PRIMARY KEY, task_id VARCHAR(36) NOT NULL, -- Question question TEXT NOT NULL, context TEXT, asked_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, -- Response response TEXT, responded_at TIMESTAMP NULL, responded_by VARCHAR(36), -- Status status ENUM('pending', 'answered', 'skipped') DEFAULT 'pending', FOREIGN KEY (task_id) REFERENCES tasks(id) ON DELETE CASCADE, INDEX idx_task_status (task_id, status), INDEX idx_status (status) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; ``` ### Tabla: agents ```sql CREATE TABLE agents ( id VARCHAR(36) PRIMARY KEY, -- K8s info pod_name VARCHAR(253) NOT NULL UNIQUE, k8s_namespace VARCHAR(63) DEFAULT 'agents', node_name VARCHAR(253), -- Status status ENUM('idle', 'busy', 'error', 'offline', 'initializing') DEFAULT 'initializing', current_task_id VARCHAR(36), -- Capabilities capabilities JSON, -- ['javascript', 'python', 'react', ...] max_concurrent_tasks INT DEFAULT 1, -- Health last_heartbeat TIMESTAMP NULL, error_message TEXT, restarts_count INT DEFAULT 0, -- Metrics tasks_completed INT DEFAULT 0, total_runtime_minutes INT DEFAULT 0, -- Timestamps created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (current_task_id) REFERENCES tasks(id) ON DELETE SET NULL, INDEX idx_status (status), INDEX idx_pod_name (pod_name), INDEX idx_last_heartbeat (last_heartbeat) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; ``` ### Tabla: task_groups ```sql CREATE TABLE task_groups ( id VARCHAR(36) PRIMARY KEY, project_id VARCHAR(36) NOT NULL, -- Grouping task_ids JSON NOT NULL, -- ['task-id-1', 'task-id-2', ...] -- Staging staging_branch VARCHAR(255), staging_pr_number INT, staging_pr_url VARCHAR(512), staging_deployed_at TIMESTAMP NULL, -- Production production_deployed_at TIMESTAMP NULL, production_rollback_available BOOLEAN DEFAULT TRUE, -- Status status ENUM('pending', 'staging', 'production', 'rolled_back') DEFAULT 'pending', -- Metadata created_by VARCHAR(36), notes TEXT, -- Timestamps created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE, INDEX idx_project_status (project_id, status), INDEX idx_status (status) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; ``` ### Tabla: deployments ```sql CREATE TABLE deployments ( id VARCHAR(36) PRIMARY KEY, project_id VARCHAR(36) NOT NULL, task_group_id VARCHAR(36), -- Deployment info environment ENUM('preview', 'staging', 'production') NOT NULL, deployment_type ENUM('manual', 'automatic', 'rollback') DEFAULT 'manual', -- Git info branch VARCHAR(255), commit_hash VARCHAR(40), -- K8s info k8s_namespace VARCHAR(63), k8s_deployment_name VARCHAR(253), image_tag VARCHAR(255), -- Status status ENUM('pending', 'in_progress', 'completed', 'failed', 'rolled_back') DEFAULT 'pending', -- Results url VARCHAR(512), error_message TEXT, logs TEXT, -- Timing started_at TIMESTAMP NULL, completed_at TIMESTAMP NULL, duration_seconds INT, -- Metadata triggered_by VARCHAR(36), -- Timestamps created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE, FOREIGN KEY (task_group_id) REFERENCES task_groups(id) ON DELETE SET NULL, INDEX idx_project_env (project_id, environment), INDEX idx_status (status), INDEX idx_created_at (created_at) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; ``` ### Tabla: agent_logs ```sql CREATE TABLE agent_logs ( id BIGINT AUTO_INCREMENT PRIMARY KEY, agent_id VARCHAR(36) NOT NULL, task_id VARCHAR(36), -- Log entry level ENUM('debug', 'info', 'warn', 'error') DEFAULT 'info', message TEXT NOT NULL, metadata JSON, -- Timestamp created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (agent_id) REFERENCES agents(id) ON DELETE CASCADE, FOREIGN KEY (task_id) REFERENCES tasks(id) ON DELETE SET NULL, INDEX idx_agent_created (agent_id, created_at), INDEX idx_task_created (task_id, created_at), INDEX idx_level (level) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; ``` ## Índices y Optimizaciones ### Índices Compuestos Importantes ```sql -- Búsqueda de tareas por proyecto y estado CREATE INDEX idx_tasks_project_state ON tasks(project_id, state, created_at); -- Búsqueda de agentes disponibles CREATE INDEX idx_agents_available ON agents(status, last_heartbeat) WHERE status = 'idle'; -- Logs recientes por agente CREATE INDEX idx_agent_logs_recent ON agent_logs(agent_id, created_at DESC) USING BTREE; ``` ### Particionamiento (para logs) ```sql -- Particionar agent_logs por mes ALTER TABLE agent_logs PARTITION BY RANGE (YEAR(created_at) * 100 + MONTH(created_at)) ( PARTITION p202601 VALUES LESS THAN (202602), PARTITION p202602 VALUES LESS THAN (202603), PARTITION p202603 VALUES LESS THAN (202604), -- ... auto-crear con script PARTITION p_future VALUES LESS THAN MAXVALUE ); ``` ## Queries Comunes ### Obtener siguiente tarea disponible ```sql SELECT * FROM tasks WHERE state = 'backlog' AND project_id = ? ORDER BY priority DESC, created_at ASC LIMIT 1 FOR UPDATE SKIP LOCKED; ``` ### Agentes disponibles ```sql SELECT * FROM agents WHERE status = 'idle' AND last_heartbeat > DATE_SUB(NOW(), INTERVAL 60 SECOND) ORDER BY tasks_completed ASC LIMIT 1; ``` ### Dashboard: Métricas de proyecto ```sql SELECT COUNT(*) as total_tasks, SUM(CASE WHEN state = 'backlog' THEN 1 ELSE 0 END) as backlog, SUM(CASE WHEN state = 'in_progress' THEN 1 ELSE 0 END) as in_progress, SUM(CASE WHEN state = 'needs_input' THEN 1 ELSE 0 END) as needs_input, SUM(CASE WHEN state = 'ready_to_test' THEN 1 ELSE 0 END) as ready_to_test, SUM(CASE WHEN state = 'production' THEN 1 ELSE 0 END) as completed, AVG(actual_duration_minutes) as avg_duration FROM tasks WHERE project_id = ?; ``` ### Historial de deployments ```sql SELECT d.*, tg.task_ids, COUNT(t.id) as tasks_count FROM deployments d LEFT JOIN task_groups tg ON d.task_group_id = tg.id LEFT JOIN tasks t ON JSON_CONTAINS(tg.task_ids, CONCAT('"', t.id, '"')) WHERE d.project_id = ? AND d.environment = 'production' GROUP BY d.id ORDER BY d.created_at DESC LIMIT 20; ``` ## Migraciones con Drizzle ```typescript // drizzle/schema.ts import { mysqlTable, varchar, text, timestamp, json, int, mysqlEnum } from 'drizzle-orm/mysql-core' export const projects = mysqlTable('projects', { id: varchar('id', { length: 36 }).primaryKey(), name: varchar('name', { length: 255 }).notNull(), description: text('description'), giteaRepoId: int('gitea_repo_id'), giteaRepoUrl: varchar('gitea_repo_url', { length: 512 }), // ... resto campos createdAt: timestamp('created_at').defaultNow(), updatedAt: timestamp('updated_at').defaultNow().onUpdateNow(), }) export const tasks = mysqlTable('tasks', { id: varchar('id', { length: 36 }).primaryKey(), projectId: varchar('project_id', { length: 36 }).notNull().references(() => projects.id), title: varchar('title', { length: 255 }).notNull(), state: mysqlEnum('state', [ 'backlog', 'in_progress', 'needs_input', 'ready_to_test', 'approved', 'staging', 'production', 'cancelled' ]).default('backlog'), // ... resto campos }) ``` ## Backup Strategy ```bash # Daily backup mysqldump -u root -p aiworker \ --single-transaction \ --quick \ --lock-tables=false \ > backup-$(date +%Y%m%d).sql # Restore mysql -u root -p aiworker < backup-20260119.sql ```