-- ============================================ -- LOG DE REQUESTS A SERVICIOS IA -- Sistema TZZR - contratos-comunes -- ============================================ -- Requiere: 00_types.sql, 02_task_manager.sql, 03_work_log.sql, 04_ai_context.sql -- ============================================ -- TABLA: task_ai_requests -- Registro de todas las requests a servicios IA -- ============================================ CREATE TABLE IF NOT EXISTS task_ai_requests ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Trazabilidad S-CONTRACT trace_id VARCHAR(64) NOT NULL, -- trace_id del S-CONTRACT idempotency_key VARCHAR(64), -- Para deduplicación step_id VARCHAR(64), -- ID del paso en cadena step_index INTEGER, -- Posición en la cadena -- Origen task_id UUID REFERENCES task_manager(id) ON DELETE SET NULL, work_log_id UUID REFERENCES task_work_log(id) ON DELETE SET NULL, project_id UUID REFERENCES task_projects(id) ON DELETE SET NULL, -- Destino target_service ai_service NOT NULL, target_module VARCHAR(50) NOT NULL, -- ASR_ENGINE, CLASSIFIER, OCR_CORE, etc. -- Contexto usado context_id UUID REFERENCES task_contexts(id) ON DELETE SET NULL, context_snapshot JSONB, -- Snapshot del contexto en el momento -- Deployment deployment_mode deployment_mode, tier_requested provider_tier, tier_used provider_tier, provider_used VARCHAR(50), endpoint_used TEXT, -- Request (sin contenido sensible) request_summary JSONB, -- Resumen de la request payload_type VARCHAR(50), -- text, audio, image, document payload_size_bytes BIGINT, payload_hash VARCHAR(64), -- Response status VARCHAR(20) NOT NULL, -- SUCCESS, PARTIAL, ERROR, TIMEOUT, FALLBACK fallback_level INTEGER DEFAULT 0, response_summary JSONB, -- Resumen de respuesta output_schema VARCHAR(100), output_hash VARCHAR(64), -- Calidad confidence DECIMAL(4,3), coverage DECIMAL(4,3), validation_passed BOOLEAN, -- Métricas latency_ms INTEGER, queue_wait_ms INTEGER, tokens_input INTEGER, tokens_output INTEGER, cost_usd DECIMAL(10,6), -- Errores error_code VARCHAR(50), error_message TEXT, retry_count INTEGER DEFAULT 0, -- Timestamps timestamp_init TIMESTAMP NOT NULL, timestamp_end TIMESTAMP, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Índices principales CREATE INDEX IF NOT EXISTS idx_ai_requests_trace ON task_ai_requests(trace_id); CREATE INDEX IF NOT EXISTS idx_ai_requests_idempotency ON task_ai_requests(idempotency_key); CREATE INDEX IF NOT EXISTS idx_ai_requests_task ON task_ai_requests(task_id); CREATE INDEX IF NOT EXISTS idx_ai_requests_work_log ON task_ai_requests(work_log_id); CREATE INDEX IF NOT EXISTS idx_ai_requests_project ON task_ai_requests(project_id); CREATE INDEX IF NOT EXISTS idx_ai_requests_service ON task_ai_requests(target_service); CREATE INDEX IF NOT EXISTS idx_ai_requests_module ON task_ai_requests(target_module); CREATE INDEX IF NOT EXISTS idx_ai_requests_status ON task_ai_requests(status); CREATE INDEX IF NOT EXISTS idx_ai_requests_fecha ON task_ai_requests(timestamp_init); CREATE INDEX IF NOT EXISTS idx_ai_requests_tier ON task_ai_requests(tier_used); CREATE INDEX IF NOT EXISTS idx_ai_requests_provider ON task_ai_requests(provider_used); -- Índice para métricas temporales CREATE INDEX IF NOT EXISTS idx_ai_requests_fecha_service ON task_ai_requests(timestamp_init, target_service); -- ============================================ -- TABLA: task_ai_request_chain -- Cadenas de requests relacionadas -- ============================================ CREATE TABLE IF NOT EXISTS task_ai_request_chain ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Trace principal de la cadena chain_trace_id VARCHAR(64) NOT NULL, -- Request en la cadena request_id UUID NOT NULL REFERENCES task_ai_requests(id) ON DELETE CASCADE, -- Posición chain_index INTEGER NOT NULL, -- Dependencias (requests previas necesarias) depends_on JSONB DEFAULT '[]', -- Array de request_ids created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, CONSTRAINT unique_chain_position UNIQUE(chain_trace_id, chain_index) ); CREATE INDEX IF NOT EXISTS idx_request_chain_trace ON task_ai_request_chain(chain_trace_id); CREATE INDEX IF NOT EXISTS idx_request_chain_request ON task_ai_request_chain(request_id); -- ============================================ -- VISTAS DE MÉTRICAS -- ============================================ -- Vista: Métricas por servicio (últimos 30 días) CREATE OR REPLACE VIEW v_ai_metrics_by_service AS SELECT target_service, target_module, COUNT(*) AS total_requests, COUNT(*) FILTER (WHERE status = 'SUCCESS') AS successful, COUNT(*) FILTER (WHERE status = 'ERROR') AS errors, COUNT(*) FILTER (WHERE status = 'FALLBACK') AS fallbacks, ROUND(AVG(latency_ms)::numeric, 2) AS avg_latency_ms, ROUND(PERCENTILE_CONT(0.95) WITHIN GROUP (ORDER BY latency_ms)::numeric, 2) AS p95_latency_ms, SUM(cost_usd) AS total_cost_usd, SUM(tokens_input) AS total_tokens_in, SUM(tokens_output) AS total_tokens_out, ROUND(AVG(confidence)::numeric, 3) AS avg_confidence FROM task_ai_requests WHERE timestamp_init > CURRENT_DATE - INTERVAL '30 days' GROUP BY target_service, target_module ORDER BY total_requests DESC; -- Vista: Métricas por tier CREATE OR REPLACE VIEW v_ai_metrics_by_tier AS SELECT tier_used, provider_used, COUNT(*) AS total_requests, COUNT(*) FILTER (WHERE status = 'SUCCESS') AS successful, ROUND(AVG(latency_ms)::numeric, 2) AS avg_latency_ms, SUM(cost_usd) AS total_cost_usd FROM task_ai_requests WHERE timestamp_init > CURRENT_DATE - INTERVAL '30 days' AND tier_used IS NOT NULL GROUP BY tier_used, provider_used ORDER BY total_requests DESC; -- Vista: Costos diarios CREATE OR REPLACE VIEW v_ai_daily_costs AS SELECT DATE(timestamp_init) AS fecha, target_service, COUNT(*) AS requests, SUM(cost_usd) AS cost_usd, SUM(tokens_input) AS tokens_in, SUM(tokens_output) AS tokens_out FROM task_ai_requests WHERE timestamp_init > CURRENT_DATE - INTERVAL '30 days' GROUP BY DATE(timestamp_init), target_service ORDER BY fecha DESC, cost_usd DESC; -- Vista: Errores recientes CREATE OR REPLACE VIEW v_ai_recent_errors AS SELECT id, trace_id, target_service, target_module, status, error_code, error_message, provider_used, tier_used, timestamp_init FROM task_ai_requests WHERE status IN ('ERROR', 'TIMEOUT') AND timestamp_init > CURRENT_DATE - INTERVAL '7 days' ORDER BY timestamp_init DESC LIMIT 100; -- ============================================ -- FUNCIÓN: Registrar request de S-CONTRACT -- ============================================ CREATE OR REPLACE FUNCTION log_ai_request( p_trace_id VARCHAR(64), p_service ai_service, p_module VARCHAR(50), p_context_id UUID DEFAULT NULL, p_task_id UUID DEFAULT NULL, p_work_log_id UUID DEFAULT NULL ) RETURNS UUID AS $$ DECLARE new_id UUID; ctx_snapshot JSONB; BEGIN -- Obtener snapshot del contexto si existe IF p_context_id IS NOT NULL THEN ctx_snapshot := build_ai_context(p_context_id); END IF; INSERT INTO task_ai_requests ( trace_id, target_service, target_module, context_id, context_snapshot, task_id, work_log_id, status, timestamp_init ) VALUES ( p_trace_id, p_service, p_module, p_context_id, ctx_snapshot, p_task_id, p_work_log_id, 'pending', CURRENT_TIMESTAMP ) RETURNING id INTO new_id; RETURN new_id; END; $$ LANGUAGE plpgsql; -- ============================================ -- FUNCIÓN: Actualizar request completada -- ============================================ CREATE OR REPLACE FUNCTION complete_ai_request( p_request_id UUID, p_status VARCHAR(20), p_tier_used provider_tier, p_provider VARCHAR(50), p_latency_ms INTEGER, p_tokens_in INTEGER DEFAULT NULL, p_tokens_out INTEGER DEFAULT NULL, p_cost_usd DECIMAL(10,6) DEFAULT NULL, p_confidence DECIMAL(4,3) DEFAULT NULL, p_error_code VARCHAR(50) DEFAULT NULL, p_error_message TEXT DEFAULT NULL ) RETURNS VOID AS $$ BEGIN UPDATE task_ai_requests SET status = p_status, tier_used = p_tier_used, provider_used = p_provider, latency_ms = p_latency_ms, tokens_input = p_tokens_in, tokens_output = p_tokens_out, cost_usd = p_cost_usd, confidence = p_confidence, error_code = p_error_code, error_message = p_error_message, timestamp_end = CURRENT_TIMESTAMP WHERE id = p_request_id; END; $$ LANGUAGE plpgsql;