queries.ts 9.4 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309
  1. import { DatabaseClient } from './client';
  2. import {
  3. ModelSuccessRate,
  4. ModelLatency,
  5. CostAnalysis,
  6. ErrorDistribution,
  7. FailedCase,
  8. PerformanceTrend,
  9. ModelComparison
  10. } from './types';
  11. const db = DatabaseClient.getInstance();
  12. // Performance analysis queries
  13. export async function getSuccessRatesByModel(): Promise<ModelSuccessRate[]> {
  14. const stmt = db.getDatabase().prepare(`
  15. SELECT
  16. model_id,
  17. COUNT(*) as total_runs,
  18. SUM(CASE WHEN succeeded THEN 1 ELSE 0 END) as successful_runs,
  19. ROUND(AVG(CASE WHEN succeeded THEN 1.0 ELSE 0.0 END) * 100, 2) as success_rate
  20. FROM results
  21. WHERE error_enum NOT IN (1, 6, 7) OR error_enum IS NULL -- Exclude: no_tool_calls, wrong_tool_call, wrong_file_edited
  22. GROUP BY model_id
  23. ORDER BY success_rate DESC, total_runs DESC
  24. `);
  25. return stmt.all() as ModelSuccessRate[];
  26. }
  27. export async function getAverageLatencyByModel(): Promise<ModelLatency[]> {
  28. const stmt = db.getDatabase().prepare(`
  29. SELECT
  30. model_id,
  31. ROUND(AVG(time_to_first_token_ms), 2) as avg_time_to_first_token_ms,
  32. ROUND(AVG(time_to_first_edit_ms), 2) as avg_time_to_first_edit_ms,
  33. ROUND(AVG(time_round_trip_ms), 2) as avg_time_round_trip_ms
  34. FROM results
  35. WHERE time_to_first_token_ms IS NOT NULL
  36. GROUP BY model_id
  37. ORDER BY avg_time_round_trip_ms ASC
  38. `);
  39. return stmt.all() as ModelLatency[];
  40. }
  41. export async function getCostAnalysisByRun(): Promise<CostAnalysis[]> {
  42. const stmt = db.getDatabase().prepare(`
  43. SELECT
  44. run_id,
  45. model_id,
  46. ROUND(SUM(cost_usd), 4) as total_cost_usd,
  47. ROUND(AVG(cost_usd), 4) as avg_cost_per_case,
  48. SUM(completion_tokens) as total_completion_tokens
  49. FROM results
  50. WHERE cost_usd IS NOT NULL
  51. GROUP BY run_id, model_id
  52. ORDER BY total_cost_usd DESC
  53. `);
  54. return stmt.all() as CostAnalysis[];
  55. }
  56. // Error analysis queries
  57. export async function getErrorDistribution(): Promise<ErrorDistribution[]> {
  58. const stmt = db.getDatabase().prepare(`
  59. SELECT
  60. error_enum,
  61. COUNT(*) as count,
  62. ROUND(COUNT(*) * 100.0 / (SELECT COUNT(*) FROM results WHERE succeeded = 0), 2) as percentage
  63. FROM results
  64. WHERE succeeded = 0 AND error_enum IS NOT NULL
  65. GROUP BY error_enum
  66. ORDER BY count DESC
  67. `);
  68. return stmt.all() as ErrorDistribution[];
  69. }
  70. export async function getFailedCasesByError(errorEnum?: number): Promise<FailedCase[]> {
  71. let query = `
  72. SELECT
  73. r.case_id,
  74. r.model_id,
  75. r.error_enum,
  76. c.description,
  77. r.raw_model_output
  78. FROM results r
  79. JOIN cases c ON r.case_id = c.case_id
  80. WHERE r.succeeded = 0
  81. `;
  82. const params: any[] = [];
  83. if (errorEnum !== undefined) {
  84. query += ` AND r.error_enum = ?`;
  85. params.push(errorEnum);
  86. }
  87. query += ` ORDER BY r.created_at DESC LIMIT 100`;
  88. const stmt = db.getDatabase().prepare(query);
  89. return stmt.all(...params) as FailedCase[];
  90. }
  91. // Trend analysis queries
  92. export async function getPerformanceTrends(days: number = 30): Promise<PerformanceTrend[]> {
  93. const stmt = db.getDatabase().prepare(`
  94. SELECT
  95. DATE(r.created_at) as date,
  96. r.model_id,
  97. ROUND(AVG(CASE WHEN r.succeeded THEN 1.0 ELSE 0.0 END) * 100, 2) as success_rate,
  98. ROUND(AVG(r.time_round_trip_ms), 2) as avg_latency_ms,
  99. ROUND(AVG(r.cost_usd), 4) as avg_cost_usd
  100. FROM results r
  101. WHERE r.created_at >= datetime('now', '-' || ? || ' days')
  102. AND (r.error_enum NOT IN (1, 6, 7) OR r.error_enum IS NULL) -- Exclude: no_tool_calls, wrong_tool_call, wrong_file_edited
  103. GROUP BY DATE(r.created_at), r.model_id
  104. ORDER BY date DESC, model_id
  105. `);
  106. return stmt.all(days) as PerformanceTrend[];
  107. }
  108. export async function getModelComparisons(): Promise<ModelComparison[]> {
  109. const stmt = db.getDatabase().prepare(`
  110. SELECT
  111. model_id,
  112. ROUND(AVG(CASE WHEN succeeded THEN 1.0 ELSE 0.0 END) * 100, 2) as success_rate,
  113. ROUND(AVG(time_round_trip_ms), 2) as avg_latency_ms,
  114. ROUND(AVG(cost_usd), 4) as avg_cost_usd,
  115. COUNT(*) as total_runs
  116. FROM results
  117. WHERE error_enum NOT IN (1, 6, 7) OR error_enum IS NULL -- Exclude: no_tool_calls, wrong_tool_call, wrong_file_edited
  118. GROUP BY model_id
  119. HAVING total_runs >= 10
  120. ORDER BY success_rate DESC, avg_latency_ms ASC
  121. `);
  122. return stmt.all() as ModelComparison[];
  123. }
  124. // Advanced analysis queries
  125. export async function getTopPerformingCases(limit: number = 10): Promise<Array<{
  126. case_id: string;
  127. description: string;
  128. success_rate: number;
  129. avg_latency_ms: number;
  130. total_runs: number;
  131. }>> {
  132. const stmt = db.getDatabase().prepare(`
  133. SELECT
  134. c.case_id,
  135. c.description,
  136. ROUND(AVG(CASE WHEN r.succeeded THEN 1.0 ELSE 0.0 END) * 100, 2) as success_rate,
  137. ROUND(AVG(r.time_round_trip_ms), 2) as avg_latency_ms,
  138. COUNT(r.result_id) as total_runs
  139. FROM cases c
  140. JOIN results r ON c.case_id = r.case_id
  141. WHERE r.error_enum NOT IN (1, 6, 7) OR r.error_enum IS NULL -- Exclude: no_tool_calls, wrong_tool_call, wrong_file_edited
  142. GROUP BY c.case_id, c.description
  143. HAVING total_runs >= 5
  144. ORDER BY success_rate DESC, avg_latency_ms ASC
  145. LIMIT ?
  146. `);
  147. return stmt.all(limit) as Array<{
  148. case_id: string;
  149. description: string;
  150. success_rate: number;
  151. avg_latency_ms: number;
  152. total_runs: number;
  153. }>;
  154. }
  155. export async function getWorstPerformingCases(limit: number = 10): Promise<Array<{
  156. case_id: string;
  157. description: string;
  158. success_rate: number;
  159. avg_latency_ms: number;
  160. total_runs: number;
  161. }>> {
  162. const stmt = db.getDatabase().prepare(`
  163. SELECT
  164. c.case_id,
  165. c.description,
  166. ROUND(AVG(CASE WHEN r.succeeded THEN 1.0 ELSE 0.0 END) * 100, 2) as success_rate,
  167. ROUND(AVG(r.time_round_trip_ms), 2) as avg_latency_ms,
  168. COUNT(r.result_id) as total_runs
  169. FROM cases c
  170. JOIN results r ON c.case_id = r.case_id
  171. WHERE r.error_enum NOT IN (1, 6, 7) OR r.error_enum IS NULL -- Exclude: no_tool_calls, wrong_tool_call, wrong_file_edited
  172. GROUP BY c.case_id, c.description
  173. HAVING total_runs >= 5
  174. ORDER BY success_rate ASC, avg_latency_ms DESC
  175. LIMIT ?
  176. `);
  177. return stmt.all(limit) as Array<{
  178. case_id: string;
  179. description: string;
  180. success_rate: number;
  181. avg_latency_ms: number;
  182. total_runs: number;
  183. }>;
  184. }
  185. export async function getModelPerformanceByTimeOfDay(): Promise<Array<{
  186. model_id: string;
  187. hour: number;
  188. success_rate: number;
  189. avg_latency_ms: number;
  190. total_runs: number;
  191. }>> {
  192. const stmt = db.getDatabase().prepare(`
  193. SELECT
  194. model_id,
  195. CAST(strftime('%H', created_at) AS INTEGER) as hour,
  196. ROUND(AVG(CASE WHEN succeeded THEN 1.0 ELSE 0.0 END) * 100, 2) as success_rate,
  197. ROUND(AVG(time_round_trip_ms), 2) as avg_latency_ms,
  198. COUNT(*) as total_runs
  199. FROM results
  200. GROUP BY model_id, hour
  201. HAVING total_runs >= 5
  202. ORDER BY model_id, hour
  203. `);
  204. return stmt.all() as Array<{
  205. model_id: string;
  206. hour: number;
  207. success_rate: number;
  208. avg_latency_ms: number;
  209. total_runs: number;
  210. }>;
  211. }
  212. export async function getRunComparison(runId1: string, runId2: string): Promise<{
  213. run1: { run_id: string; success_rate: number; avg_latency_ms: number; avg_cost_usd: number; total_cases: number };
  214. run2: { run_id: string; success_rate: number; avg_latency_ms: number; avg_cost_usd: number; total_cases: number };
  215. }> {
  216. const stmt = db.getDatabase().prepare(`
  217. SELECT
  218. run_id,
  219. ROUND(AVG(CASE WHEN succeeded THEN 1.0 ELSE 0.0 END) * 100, 2) as success_rate,
  220. ROUND(AVG(time_round_trip_ms), 2) as avg_latency_ms,
  221. ROUND(AVG(cost_usd), 4) as avg_cost_usd,
  222. COUNT(DISTINCT case_id) as total_cases
  223. FROM results
  224. WHERE run_id IN (?, ?)
  225. GROUP BY run_id
  226. `);
  227. const results = stmt.all(runId1, runId2) as Array<{
  228. run_id: string;
  229. success_rate: number;
  230. avg_latency_ms: number;
  231. avg_cost_usd: number;
  232. total_cases: number;
  233. }>;
  234. const run1 = results.find(r => r.run_id === runId1);
  235. const run2 = results.find(r => r.run_id === runId2);
  236. if (!run1 || !run2) {
  237. throw new Error('One or both runs not found');
  238. }
  239. return { run1, run2 };
  240. }
  241. // Summary statistics
  242. export async function getDatabaseSummary(): Promise<{
  243. total_runs: number;
  244. total_cases: number;
  245. total_results: number;
  246. valid_results: number;
  247. unique_models: number;
  248. overall_success_rate: number;
  249. date_range: { earliest: string; latest: string };
  250. }> {
  251. const stmt = db.getDatabase().prepare(`
  252. SELECT
  253. (SELECT COUNT(*) FROM runs) as total_runs,
  254. (SELECT COUNT(*) FROM cases) as total_cases,
  255. (SELECT COUNT(*) FROM results) as total_results,
  256. (SELECT COUNT(*) FROM results WHERE error_enum NOT IN (1, 6, 7) OR error_enum IS NULL) as valid_results,
  257. (SELECT COUNT(DISTINCT model_id) FROM results) as unique_models,
  258. (SELECT ROUND(AVG(CASE WHEN succeeded THEN 1.0 ELSE 0.0 END) * 100, 2)
  259. FROM results
  260. WHERE error_enum NOT IN (1, 6, 7) OR error_enum IS NULL) as overall_success_rate,
  261. (SELECT MIN(created_at) FROM results) as earliest,
  262. (SELECT MAX(created_at) FROM results) as latest
  263. FROM results
  264. LIMIT 1
  265. `);
  266. const result = stmt.get() as any;
  267. return {
  268. total_runs: result.total_runs || 0,
  269. total_cases: result.total_cases || 0,
  270. total_results: result.total_results || 0,
  271. valid_results: result.valid_results || 0,
  272. unique_models: result.unique_models || 0,
  273. overall_success_rate: result.overall_success_rate || 0,
  274. date_range: {
  275. earliest: result.earliest || '',
  276. latest: result.latest || ''
  277. }
  278. };
  279. }