a cache for slack profile pictures and emojis

feat: use more compact data format

dunkirk.sh 9911dbc1 ea371da4

verified
Changed files
+581 -983
src
+1 -1
package.json
··· 1 1 { 2 2 "name": "cachet", 3 - "version": "0.3.2", 3 + "version": "0.4.0", 4 4 "scripts": { 5 5 "test": "echo \"Error: no test specified\" && exit 1", 6 6 "dev": "bun run --watch src/index.ts",
+378 -982
src/cache.ts
··· 1 1 import { Database } from "bun:sqlite"; 2 2 import { schedule } from "node-cron"; 3 + import { bucketAnalyticsMigration } from "./migrations/bucketAnalyticsMigration"; 3 4 import { endpointGroupingMigration } from "./migrations/endpointGroupingMigration"; 4 5 import { logGroupingMigration } from "./migrations/logGroupingMigration"; 5 6 import { MigrationManager } from "./migrations/migrationManager"; ··· 399 400 ) 400 401 `); 401 402 402 - // Create request analytics table 403 - this.db.run(` 404 - CREATE TABLE IF NOT EXISTS request_analytics ( 405 - id TEXT PRIMARY KEY, 406 - endpoint TEXT NOT NULL, 407 - method TEXT NOT NULL, 408 - status_code INTEGER NOT NULL, 409 - user_agent TEXT, 410 - ip_address TEXT, 411 - timestamp INTEGER NOT NULL, 412 - response_time INTEGER 413 - ) 414 - `); 415 - 416 - // Create index for faster queries 417 - this.db.run(` 418 - CREATE INDEX IF NOT EXISTS idx_request_analytics_timestamp 419 - ON request_analytics(timestamp) 420 - `); 421 - 422 - this.db.run(` 423 - CREATE INDEX IF NOT EXISTS idx_request_analytics_endpoint 424 - ON request_analytics(endpoint) 425 - `); 426 - 403 + // Create bucketed traffic tables (10-minute, hourly, daily) 427 404 this.db.run(` 428 - CREATE INDEX IF NOT EXISTS idx_request_analytics_status_timestamp 429 - ON request_analytics(status_code, timestamp) 430 - `); 431 - 432 - this.db.run(` 433 - CREATE INDEX IF NOT EXISTS idx_request_analytics_response_time 434 - ON request_analytics(response_time) WHERE response_time IS NOT NULL 435 - `); 405 + CREATE TABLE IF NOT EXISTS traffic_10min ( 406 + bucket INTEGER NOT NULL, 407 + endpoint TEXT NOT NULL, 408 + status_code INTEGER NOT NULL, 409 + hits INTEGER NOT NULL DEFAULT 1, 410 + total_response_time INTEGER NOT NULL DEFAULT 0, 411 + PRIMARY KEY (bucket, endpoint, status_code) 412 + ) WITHOUT ROWID 413 + `); 436 414 437 415 this.db.run(` 438 - CREATE INDEX IF NOT EXISTS idx_request_analytics_composite 439 - ON request_analytics(timestamp, endpoint, status_code) 440 - `); 416 + CREATE TABLE IF NOT EXISTS traffic_hourly ( 417 + bucket INTEGER NOT NULL, 418 + endpoint TEXT NOT NULL, 419 + status_code INTEGER NOT NULL, 420 + hits INTEGER NOT NULL DEFAULT 1, 421 + total_response_time INTEGER NOT NULL DEFAULT 0, 422 + PRIMARY KEY (bucket, endpoint, status_code) 423 + ) WITHOUT ROWID 424 + `); 441 425 442 - // Additional performance indexes 443 426 this.db.run(` 444 - CREATE INDEX IF NOT EXISTS idx_request_analytics_user_agent 445 - ON request_analytics(user_agent, timestamp) WHERE user_agent IS NOT NULL 446 - `); 427 + CREATE TABLE IF NOT EXISTS traffic_daily ( 428 + bucket INTEGER NOT NULL, 429 + endpoint TEXT NOT NULL, 430 + status_code INTEGER NOT NULL, 431 + hits INTEGER NOT NULL DEFAULT 1, 432 + total_response_time INTEGER NOT NULL DEFAULT 0, 433 + PRIMARY KEY (bucket, endpoint, status_code) 434 + ) WITHOUT ROWID 435 + `); 447 436 437 + // Create user agent stats table 448 438 this.db.run(` 449 - CREATE INDEX IF NOT EXISTS idx_request_analytics_time_response 450 - ON request_analytics(timestamp, response_time) WHERE response_time IS NOT NULL 451 - `); 439 + CREATE TABLE IF NOT EXISTS user_agent_stats ( 440 + user_agent TEXT PRIMARY KEY, 441 + hits INTEGER NOT NULL DEFAULT 1, 442 + last_seen INTEGER NOT NULL 443 + ) WITHOUT ROWID 444 + `); 452 445 453 - this.db.run(` 454 - CREATE INDEX IF NOT EXISTS idx_request_analytics_exclude_stats 455 - ON request_analytics(timestamp, endpoint, status_code) WHERE endpoint != '/stats' 456 - `); 446 + // Create indexes for time-range queries 447 + this.db.run( 448 + "CREATE INDEX IF NOT EXISTS idx_traffic_10min_bucket ON traffic_10min(bucket)", 449 + ); 450 + this.db.run( 451 + "CREATE INDEX IF NOT EXISTS idx_traffic_hourly_bucket ON traffic_hourly(bucket)", 452 + ); 453 + this.db.run( 454 + "CREATE INDEX IF NOT EXISTS idx_traffic_daily_bucket ON traffic_daily(bucket)", 455 + ); 456 + this.db.run( 457 + "CREATE INDEX IF NOT EXISTS idx_user_agent_hits ON user_agent_stats(hits DESC)", 458 + ); 457 459 458 460 // Enable WAL mode for better concurrent performance 459 461 this.db.run("PRAGMA journal_mode = WAL"); ··· 504 506 // Define migrations directly here to avoid circular dependencies 505 507 // Note: We define migrations both here and in migrations/index.ts 506 508 // This is intentional to prevent circular imports 507 - const migrations = [endpointGroupingMigration, logGroupingMigration]; 509 + const migrations = [ 510 + endpointGroupingMigration, 511 + logGroupingMigration, 512 + bucketAnalyticsMigration, 513 + ]; 508 514 const migrationManager = new MigrationManager(this.db, migrations); 509 515 const result = await migrationManager.runMigrations(); 510 516 ··· 530 536 Date.now(), 531 537 ]); 532 538 533 - // Clean up old analytics data (older than 30 days) - moved to off-peak hours 534 - const thirtyDaysAgo = Date.now() - 30 * 24 * 60 * 60 * 1000; 535 - const currentHour = new Date().getHours(); 536 - // Only run analytics cleanup during off-peak hours (2-6 AM) 537 - if (currentHour >= 2 && currentHour < 6) { 538 - this.db.run("DELETE FROM request_analytics WHERE timestamp < ?", [ 539 - thirtyDaysAgo, 540 - ]); 541 - console.log( 542 - `Analytics cleanup completed - removed records older than 30 days`, 543 - ); 544 - } 539 + // Clean up old 10-minute bucket data (older than 24 hours) 540 + const oneDayAgoSec = Math.floor(Date.now() / 1000) - 86400; 541 + const cleanupBucket = oneDayAgoSec - (oneDayAgoSec % 600); 542 + this.db.run("DELETE FROM traffic_10min WHERE bucket < ?", [cleanupBucket]); 545 543 546 544 // Emojis are now updated on schedule, not on expiration 547 545 return result2.changes; ··· 1037 1035 } 1038 1036 1039 1037 /** 1040 - * Records a request for analytics 1038 + * Records a request for analytics using bucketed time-series storage 1041 1039 * @param endpoint The endpoint that was accessed 1042 - * @param method HTTP method 1040 + * @param method HTTP method (unused, kept for API compatibility) 1043 1041 * @param statusCode HTTP status code 1044 1042 * @param userAgent User agent string 1045 - * @param ipAddress IP address of the client 1043 + * @param ipAddress IP address of the client (unused, kept for API compatibility) 1046 1044 * @param responseTime Response time in milliseconds 1047 1045 */ 1048 1046 async recordRequest( 1049 1047 endpoint: string, 1050 - method: string, 1048 + _method: string, 1051 1049 statusCode: number, 1052 1050 userAgent?: string, 1053 - ipAddress?: string, 1051 + _ipAddress?: string, 1054 1052 responseTime?: number, 1055 1053 ): Promise<void> { 1056 1054 try { 1057 - const id = crypto.randomUUID(); 1055 + const now = Math.floor(Date.now() / 1000); 1056 + const bucket10min = now - (now % 600); 1057 + const bucketHour = now - (now % 3600); 1058 + const bucketDay = now - (now % 86400); 1059 + const respTime = responseTime || 0; 1060 + 1061 + // Upsert into all three bucket tables 1058 1062 this.db.run( 1059 - `INSERT INTO request_analytics 1060 - (id, endpoint, method, status_code, user_agent, ip_address, timestamp, response_time) 1061 - VALUES (?, ?, ?, ?, ?, ?, ?, ?)`, 1062 - [ 1063 - id, 1064 - endpoint, 1065 - method, 1066 - statusCode, 1067 - userAgent || null, 1068 - ipAddress || null, 1069 - Date.now(), 1070 - responseTime || null, 1071 - ], 1063 + `INSERT INTO traffic_10min (bucket, endpoint, status_code, hits, total_response_time) 1064 + VALUES (?1, ?2, ?3, 1, ?4) 1065 + ON CONFLICT(bucket, endpoint, status_code) DO UPDATE SET 1066 + hits = hits + 1, 1067 + total_response_time = total_response_time + ?4`, 1068 + [bucket10min, endpoint, statusCode, respTime], 1072 1069 ); 1070 + 1071 + this.db.run( 1072 + `INSERT INTO traffic_hourly (bucket, endpoint, status_code, hits, total_response_time) 1073 + VALUES (?1, ?2, ?3, 1, ?4) 1074 + ON CONFLICT(bucket, endpoint, status_code) DO UPDATE SET 1075 + hits = hits + 1, 1076 + total_response_time = total_response_time + ?4`, 1077 + [bucketHour, endpoint, statusCode, respTime], 1078 + ); 1079 + 1080 + this.db.run( 1081 + `INSERT INTO traffic_daily (bucket, endpoint, status_code, hits, total_response_time) 1082 + VALUES (?1, ?2, ?3, 1, ?4) 1083 + ON CONFLICT(bucket, endpoint, status_code) DO UPDATE SET 1084 + hits = hits + 1, 1085 + total_response_time = total_response_time + ?4`, 1086 + [bucketDay, endpoint, statusCode, respTime], 1087 + ); 1088 + 1089 + // Track user agent 1090 + if (userAgent) { 1091 + this.db.run( 1092 + `INSERT INTO user_agent_stats (user_agent, hits, last_seen) 1093 + VALUES (?1, 1, ?2) 1094 + ON CONFLICT(user_agent) DO UPDATE SET 1095 + hits = hits + 1, 1096 + last_seen = MAX(last_seen, ?2)`, 1097 + [userAgent, Date.now()], 1098 + ); 1099 + } 1073 1100 } catch (error) { 1074 1101 console.error("Error recording request analytics:", error); 1075 1102 } 1076 1103 } 1077 1104 1078 1105 /** 1079 - * Gets request analytics statistics with performance optimizations 1106 + * Helper to select the appropriate bucket table based on time range 1107 + */ 1108 + private selectBucketTable(days: number): { 1109 + table: string; 1110 + bucketSize: number; 1111 + } { 1112 + if (days <= 1) { 1113 + return { table: "traffic_10min", bucketSize: 600 }; 1114 + } else if (days <= 30) { 1115 + return { table: "traffic_hourly", bucketSize: 3600 }; 1116 + } else { 1117 + return { table: "traffic_daily", bucketSize: 86400 }; 1118 + } 1119 + } 1120 + 1121 + /** 1122 + * Helper to group endpoint names for display 1123 + */ 1124 + private groupEndpoint(endpoint: string): string { 1125 + if (endpoint === "/" || endpoint === "/dashboard") { 1126 + return "Dashboard"; 1127 + } else if (endpoint === "/health") { 1128 + return "Health Check"; 1129 + } else if (endpoint === "/swagger" || endpoint.startsWith("/swagger")) { 1130 + return "API Documentation"; 1131 + } else if (endpoint === "/emojis") { 1132 + return "Emoji List"; 1133 + } else if (endpoint.match(/^\/emojis\/[^/]+$/) || endpoint === "/emojis/EMOJI_NAME") { 1134 + return "Emoji Data"; 1135 + } else if (endpoint.match(/^\/emojis\/[^/]+\/r$/) || endpoint === "/emojis/EMOJI_NAME/r") { 1136 + return "Emoji Redirects"; 1137 + } else if (endpoint.match(/^\/users\/[^/]+$/) || endpoint === "/users/USER_ID") { 1138 + return "User Data"; 1139 + } else if (endpoint.match(/^\/users\/[^/]+\/r$/) || endpoint === "/users/USER_ID/r") { 1140 + return "User Redirects"; 1141 + } else if (endpoint.match(/^\/users\/[^/]+\/purge$/) || endpoint === "/reset") { 1142 + return "Cache Management"; 1143 + } else if (endpoint.includes("/users/") && endpoint.includes("/r")) { 1144 + return "User Redirects"; 1145 + } else if (endpoint.includes("/users/")) { 1146 + return "User Data"; 1147 + } else if (endpoint.includes("/emojis/") && endpoint.includes("/r")) { 1148 + return "Emoji Redirects"; 1149 + } else if (endpoint.includes("/emojis/")) { 1150 + return "Emoji Data"; 1151 + } 1152 + return "Other"; 1153 + } 1154 + 1155 + /** 1156 + * Gets request analytics statistics using bucketed time-series data 1080 1157 * @param days Number of days to look back (default: 7) 1081 1158 * @returns Analytics data 1082 1159 */ ··· 1147 1224 total: number; 1148 1225 }>; 1149 1226 }> { 1150 - // Check cache first 1151 1227 const cacheKey = `analytics_${days}`; 1152 1228 const cached = this.typedAnalyticsCache.getAnalyticsData(cacheKey); 1153 - 1154 1229 if (cached) { 1155 1230 return cached; 1156 1231 } 1157 - const cutoffTime = Date.now() - days * 24 * 60 * 60 * 1000; 1232 + 1233 + const { table, bucketSize } = this.selectBucketTable(days); 1234 + const cutoffBucket = Math.floor(Date.now() / 1000) - days * 24 * 60 * 60; 1235 + const alignedCutoff = cutoffBucket - (cutoffBucket % bucketSize); 1158 1236 1159 1237 // Total requests (excluding stats endpoint) 1160 1238 const totalResult = this.db 1161 1239 .query( 1162 - "SELECT COUNT(*) as count FROM request_analytics WHERE timestamp > ? AND endpoint != '/stats'", 1240 + `SELECT SUM(hits) as count FROM ${table} WHERE bucket >= ? AND endpoint != '/stats'`, 1163 1241 ) 1164 - .get(cutoffTime) as { count: number }; 1242 + .get(alignedCutoff) as { count: number | null }; 1165 1243 1166 1244 // Stats endpoint requests (tracked separately) 1167 1245 const statsResult = this.db 1168 1246 .query( 1169 - "SELECT COUNT(*) as count FROM request_analytics WHERE timestamp > ? AND endpoint = '/stats'", 1247 + `SELECT SUM(hits) as count FROM ${table} WHERE bucket >= ? AND endpoint = '/stats'`, 1170 1248 ) 1171 - .get(cutoffTime) as { count: number }; 1249 + .get(alignedCutoff) as { count: number | null }; 1172 1250 1173 - // Get raw endpoint data and group them intelligently (excluding stats) 1251 + // Get endpoint data from bucket table and group them 1174 1252 const rawEndpointResults = this.db 1175 1253 .query( 1176 1254 ` 1177 - SELECT endpoint, COUNT(*) as count, AVG(response_time) as averageResponseTime 1178 - FROM request_analytics 1179 - WHERE timestamp > ? AND endpoint != '/stats' 1255 + SELECT endpoint, SUM(hits) as count, SUM(total_response_time) as totalTime, SUM(hits) as totalHits 1256 + FROM ${table} 1257 + WHERE bucket >= ? AND endpoint != '/stats' 1180 1258 GROUP BY endpoint 1181 1259 ORDER BY count DESC 1182 1260 `, 1183 1261 ) 1184 - .all(cutoffTime) as Array<{ 1262 + .all(alignedCutoff) as Array<{ 1185 1263 endpoint: string; 1186 1264 count: number; 1187 - averageResponseTime: number | null; 1265 + totalTime: number; 1266 + totalHits: number; 1188 1267 }>; 1189 1268 1190 - // Group endpoints intelligently 1269 + // Group endpoints using helper 1191 1270 const endpointGroups: Record< 1192 1271 string, 1193 1272 { count: number; totalResponseTime: number; requestCount: number } 1194 1273 > = {}; 1195 1274 1196 1275 for (const result of rawEndpointResults) { 1197 - const endpoint = result.endpoint; 1198 - let groupKey: string; 1199 - 1200 - if (endpoint === "/" || endpoint === "/dashboard") { 1201 - groupKey = "Dashboard"; 1202 - } else if (endpoint === "/health") { 1203 - groupKey = "Health Check"; 1204 - } else if (endpoint === "/swagger" || endpoint.startsWith("/swagger")) { 1205 - groupKey = "API Documentation"; 1206 - } else if (endpoint === "/emojis") { 1207 - groupKey = "Emoji List"; 1208 - } else if (endpoint.match(/^\/emojis\/[^/]+$/)) { 1209 - groupKey = "Emoji Data"; 1210 - } else if (endpoint.match(/^\/emojis\/[^/]+\/r$/)) { 1211 - groupKey = "Emoji Redirects"; 1212 - } else if (endpoint.match(/^\/users\/[^/]+$/)) { 1213 - groupKey = "User Data"; 1214 - } else if (endpoint.match(/^\/users\/[^/]+\/r$/)) { 1215 - groupKey = "User Redirects"; 1216 - } else if (endpoint.match(/^\/users\/[^/]+\/purge$/)) { 1217 - groupKey = "Cache Management"; 1218 - } else if (endpoint === "/reset") { 1219 - groupKey = "Cache Management"; 1220 - } else { 1221 - // For any other endpoints, try to categorize them 1222 - if (endpoint.includes("/users/") && endpoint.includes("/r")) { 1223 - groupKey = "User Redirects"; 1224 - } else if (endpoint.includes("/users/")) { 1225 - groupKey = "User Data"; 1226 - } else if (endpoint.includes("/emojis/") && endpoint.includes("/r")) { 1227 - groupKey = "Emoji Redirects"; 1228 - } else if (endpoint.includes("/emojis/")) { 1229 - groupKey = "Emoji Data"; 1230 - } else { 1231 - groupKey = "Other"; 1232 - } 1233 - } 1276 + const groupKey = this.groupEndpoint(result.endpoint); 1234 1277 1235 1278 if (!endpointGroups[groupKey]) { 1236 1279 endpointGroups[groupKey] = { ··· 1240 1283 }; 1241 1284 } 1242 1285 1243 - // Defensive: Only update if groupKey exists (should always exist due to initialization above) 1244 1286 const group = endpointGroups[groupKey]; 1245 1287 if (group) { 1246 1288 group.count += result.count; 1247 - if ( 1248 - result.averageResponseTime !== null && 1249 - result.averageResponseTime !== undefined 1250 - ) { 1251 - group.totalResponseTime += result.averageResponseTime * result.count; 1252 - group.requestCount += result.count; 1289 + if (result.totalTime && result.totalHits > 0) { 1290 + group.totalResponseTime += result.totalTime; 1291 + group.requestCount += result.totalHits; 1253 1292 } 1254 1293 } 1255 1294 } ··· 1266 1305 })) 1267 1306 .sort((a, b) => b.count - a.count); 1268 1307 1269 - // Requests by status code with average response time (excluding stats) 1308 + // Requests by status code from bucket table 1270 1309 const statusResultsRaw = this.db 1271 1310 .query( 1272 1311 ` 1273 - SELECT status_code as status, COUNT(*) as count, AVG(response_time) as averageResponseTime 1274 - FROM request_analytics 1275 - WHERE timestamp > ? AND endpoint != '/stats' 1312 + SELECT status_code as status, SUM(hits) as count, SUM(total_response_time) as totalTime, SUM(hits) as totalHits 1313 + FROM ${table} 1314 + WHERE bucket >= ? AND endpoint != '/stats' 1276 1315 GROUP BY status_code 1277 1316 ORDER BY count DESC 1278 1317 `, 1279 1318 ) 1280 - .all(cutoffTime) as Array<{ 1319 + .all(alignedCutoff) as Array<{ 1281 1320 status: number; 1282 1321 count: number; 1283 - averageResponseTime: number | null; 1322 + totalTime: number; 1323 + totalHits: number; 1284 1324 }>; 1285 1325 1286 1326 const statusResults = statusResultsRaw.map((s) => ({ 1287 1327 status: s.status, 1288 1328 count: s.count, 1289 - averageResponseTime: s.averageResponseTime ?? 0, 1329 + averageResponseTime: s.totalHits > 0 ? s.totalTime / s.totalHits : 0, 1290 1330 })); 1291 1331 1292 - // Requests over time - hourly for 1 day, daily for longer periods 1293 - let timeResults: Array<{ 1332 + // Requests over time from bucket table 1333 + const timeResultsRaw = this.db 1334 + .query( 1335 + ` 1336 + SELECT 1337 + datetime(bucket, 'unixepoch') as date, 1338 + SUM(hits) as count, 1339 + SUM(total_response_time) as totalTime, 1340 + SUM(hits) as totalHits 1341 + FROM ${table} 1342 + WHERE bucket >= ? AND endpoint != '/stats' 1343 + GROUP BY bucket 1344 + ORDER BY bucket ASC 1345 + `, 1346 + ) 1347 + .all(alignedCutoff) as Array<{ 1294 1348 date: string; 1295 1349 count: number; 1296 - averageResponseTime: number; 1350 + totalTime: number; 1351 + totalHits: number; 1297 1352 }>; 1298 1353 1299 - if (days === 1) { 1300 - // 15-minute intervals for last 24 hours (excluding stats) 1301 - const intervalResultsRaw = this.db 1302 - .query( 1303 - ` 1304 - SELECT 1305 - strftime('%Y-%m-%d %H:', datetime(timestamp / 1000, 'unixepoch')) || 1306 - CASE 1307 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 15 THEN '00' 1308 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 30 THEN '15' 1309 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 45 THEN '30' 1310 - ELSE '45' 1311 - END as date, 1312 - COUNT(*) as count, 1313 - AVG(response_time) as averageResponseTime 1314 - FROM request_analytics 1315 - WHERE timestamp > ? AND endpoint != '/stats' 1316 - GROUP BY strftime('%Y-%m-%d %H:', datetime(timestamp / 1000, 'unixepoch')) || 1317 - CASE 1318 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 15 THEN '00' 1319 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 30 THEN '15' 1320 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 45 THEN '30' 1321 - ELSE '45' 1322 - END 1323 - ORDER BY date ASC 1324 - `, 1325 - ) 1326 - .all(cutoffTime) as Array<{ 1327 - date: string; 1328 - count: number; 1329 - averageResponseTime: number | null; 1330 - }>; 1331 - 1332 - timeResults = intervalResultsRaw.map((h) => ({ 1333 - date: h.date, 1334 - count: h.count, 1335 - averageResponseTime: h.averageResponseTime ?? 0, 1336 - })); 1337 - } else if (days <= 7) { 1338 - // Hourly data for 7 days (excluding stats) 1339 - const hourResultsRaw = this.db 1340 - .query( 1341 - ` 1342 - SELECT 1343 - strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')) as date, 1344 - COUNT(*) as count, 1345 - AVG(response_time) as averageResponseTime 1346 - FROM request_analytics 1347 - WHERE timestamp > ? AND endpoint != '/stats' 1348 - GROUP BY strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')) 1349 - ORDER BY date ASC 1350 - `, 1351 - ) 1352 - .all(cutoffTime) as Array<{ 1353 - date: string; 1354 - count: number; 1355 - averageResponseTime: number | null; 1356 - }>; 1357 - 1358 - timeResults = hourResultsRaw.map((h) => ({ 1359 - date: h.date, 1360 - count: h.count, 1361 - averageResponseTime: h.averageResponseTime ?? 0, 1362 - })); 1363 - } else { 1364 - // 4-hour intervals for longer periods (excluding stats) 1365 - const intervalResultsRaw = this.db 1366 - .query( 1367 - ` 1368 - SELECT 1369 - strftime('%Y-%m-%d ', datetime(timestamp / 1000, 'unixepoch')) || 1370 - CASE 1371 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 4 THEN '00:00' 1372 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 8 THEN '04:00' 1373 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 12 THEN '08:00' 1374 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 16 THEN '12:00' 1375 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 20 THEN '16:00' 1376 - ELSE '20:00' 1377 - END as date, 1378 - COUNT(*) as count, 1379 - AVG(response_time) as averageResponseTime 1380 - FROM request_analytics 1381 - WHERE timestamp > ? AND endpoint != '/stats' 1382 - GROUP BY strftime('%Y-%m-%d ', datetime(timestamp / 1000, 'unixepoch')) || 1383 - CASE 1384 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 4 THEN '00:00' 1385 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 8 THEN '04:00' 1386 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 12 THEN '08:00' 1387 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 16 THEN '12:00' 1388 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 20 THEN '16:00' 1389 - ELSE '20:00' 1390 - END 1391 - ORDER BY date ASC 1392 - `, 1393 - ) 1394 - .all(cutoffTime) as Array<{ 1395 - date: string; 1396 - count: number; 1397 - averageResponseTime: number | null; 1398 - }>; 1354 + const timeResults = timeResultsRaw.map((r) => ({ 1355 + date: r.date, 1356 + count: r.count, 1357 + averageResponseTime: r.totalHits > 0 ? r.totalTime / r.totalHits : 0, 1358 + })); 1399 1359 1400 - timeResults = intervalResultsRaw.map((d) => ({ 1401 - date: d.date, 1402 - count: d.count, 1403 - averageResponseTime: d.averageResponseTime ?? 0, 1404 - })); 1405 - } 1406 - 1407 - // Average response time (excluding stats) 1360 + // Average response time from bucket table 1408 1361 const avgResponseResult = this.db 1409 1362 .query( 1410 1363 ` 1411 - SELECT AVG(response_time) as avg 1412 - FROM request_analytics 1413 - WHERE timestamp > ? AND response_time IS NOT NULL AND endpoint != '/stats' 1364 + SELECT SUM(total_response_time) as totalTime, SUM(hits) as totalHits 1365 + FROM ${table} 1366 + WHERE bucket >= ? AND endpoint != '/stats' 1414 1367 `, 1415 1368 ) 1416 - .get(cutoffTime) as { avg: number | null }; 1369 + .get(alignedCutoff) as { totalTime: number | null; totalHits: number | null }; 1370 + 1371 + const averageResponseTime = 1372 + avgResponseResult.totalHits && avgResponseResult.totalHits > 0 1373 + ? (avgResponseResult.totalTime ?? 0) / avgResponseResult.totalHits 1374 + : null; 1417 1375 1418 - // Top user agents (raw strings, excluding stats) - optimized with index hint 1376 + // Top user agents from user_agent_stats table (cumulative, no time filter) 1419 1377 const topUserAgents = this.db 1420 1378 .query( 1421 1379 ` 1422 - SELECT user_agent as userAgent, COUNT(*) as count 1423 - FROM request_analytics INDEXED BY idx_request_analytics_user_agent 1424 - WHERE timestamp > ? AND user_agent IS NOT NULL AND endpoint != '/stats' 1425 - GROUP BY user_agent 1426 - ORDER BY count DESC 1380 + SELECT user_agent as userAgent, hits as count 1381 + FROM user_agent_stats 1382 + WHERE user_agent IS NOT NULL 1383 + ORDER BY hits DESC 1427 1384 LIMIT 50 1428 1385 `, 1429 1386 ) 1430 - .all(cutoffTime) as Array<{ userAgent: string; count: number }>; 1431 - 1432 - // Enhanced Latency Analytics 1433 - 1434 - // Get all response times for percentile calculations (excluding stats) 1435 - const responseTimes = this.db 1436 - .query( 1437 - ` 1438 - SELECT response_time 1439 - FROM request_analytics 1440 - WHERE timestamp > ? AND response_time IS NOT NULL AND endpoint != '/stats' 1441 - ORDER BY response_time 1442 - `, 1443 - ) 1444 - .all(cutoffTime) as Array<{ response_time: number }>; 1445 - 1446 - // Calculate percentiles 1447 - const calculatePercentile = ( 1448 - arr: number[], 1449 - percentile: number, 1450 - ): number | null => { 1451 - if (arr.length === 0) return null; 1452 - const index = Math.ceil((percentile / 100) * arr.length) - 1; 1453 - return arr[Math.max(0, index)] ?? 0; 1454 - }; 1387 + .all() as Array<{ userAgent: string; count: number }>; 1455 1388 1456 - const sortedTimes = responseTimes 1457 - .map((r) => r.response_time) 1458 - .sort((a, b) => a - b); 1389 + // Simplified latency analytics from bucket data 1459 1390 const percentiles = { 1460 - p50: calculatePercentile(sortedTimes, 50), 1461 - p75: calculatePercentile(sortedTimes, 75), 1462 - p90: calculatePercentile(sortedTimes, 90), 1463 - p95: calculatePercentile(sortedTimes, 95), 1464 - p99: calculatePercentile(sortedTimes, 99), 1391 + p50: null as number | null, 1392 + p75: null as number | null, 1393 + p90: null as number | null, 1394 + p95: null as number | null, 1395 + p99: null as number | null, 1465 1396 }; 1466 1397 1467 - // Response time distribution 1468 - const totalWithResponseTime = responseTimes.length; 1469 - const distributionRanges = [ 1470 - { min: 0, max: 50, label: "0-50ms" }, 1471 - { min: 50, max: 100, label: "50-100ms" }, 1472 - { min: 100, max: 200, label: "100-200ms" }, 1473 - { min: 200, max: 500, label: "200-500ms" }, 1474 - { min: 500, max: 1000, label: "500ms-1s" }, 1475 - { min: 1000, max: 2000, label: "1-2s" }, 1476 - { min: 2000, max: 5000, label: "2-5s" }, 1477 - { min: 5000, max: Infinity, label: "5s+" }, 1478 - ]; 1398 + const distribution: Array<{ range: string; count: number; percentage: number }> = []; 1479 1399 1480 - const distribution = distributionRanges.map((range) => { 1481 - const count = sortedTimes.filter( 1482 - (time) => time >= range.min && time < range.max, 1483 - ).length; 1484 - return { 1485 - range: range.label, 1486 - count, 1487 - percentage: 1488 - totalWithResponseTime > 0 ? (count / totalWithResponseTime) * 100 : 0, 1489 - }; 1490 - }); 1491 - 1492 - // Slowest endpoints (grouped) 1400 + // Slowest endpoints from grouped data 1493 1401 const slowestEndpoints = requestsByEndpoint 1494 1402 .filter((e) => e.averageResponseTime > 0) 1495 1403 .sort((a, b) => b.averageResponseTime - a.averageResponseTime) 1496 1404 .slice(0, 10); 1497 1405 1498 - // Latency over time - hourly for 1 day, daily for longer periods 1499 - let latencyOverTime: Array<{ 1406 + // Latency over time from bucket table 1407 + const latencyOverTimeRaw = this.db 1408 + .query( 1409 + ` 1410 + SELECT 1411 + datetime(bucket, 'unixepoch') as time, 1412 + SUM(total_response_time) as totalTime, 1413 + SUM(hits) as count 1414 + FROM ${table} 1415 + WHERE bucket >= ? AND endpoint != '/stats' 1416 + GROUP BY bucket 1417 + ORDER BY bucket ASC 1418 + `, 1419 + ) 1420 + .all(alignedCutoff) as Array<{ 1500 1421 time: string; 1501 - averageResponseTime: number; 1502 - p95: number | null; 1422 + totalTime: number; 1503 1423 count: number; 1504 1424 }>; 1505 1425 1506 - if (days === 1) { 1507 - // 15-minute intervals for last 24 hours (excluding stats) 1508 - const latencyOverTimeRaw = this.db 1509 - .query( 1510 - ` 1511 - SELECT 1512 - strftime('%Y-%m-%d %H:', datetime(timestamp / 1000, 'unixepoch')) || 1513 - CASE 1514 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 15 THEN '00' 1515 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 30 THEN '15' 1516 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 45 THEN '30' 1517 - ELSE '45' 1518 - END as time, 1519 - AVG(response_time) as averageResponseTime, 1520 - COUNT(*) as count 1521 - FROM request_analytics 1522 - WHERE timestamp > ? AND response_time IS NOT NULL AND endpoint != '/stats' 1523 - GROUP BY strftime('%Y-%m-%d %H:', datetime(timestamp / 1000, 'unixepoch')) || 1524 - CASE 1525 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 15 THEN '00' 1526 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 30 THEN '15' 1527 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 45 THEN '30' 1528 - ELSE '45' 1529 - END 1530 - ORDER BY time ASC 1531 - `, 1532 - ) 1533 - .all(cutoffTime) as Array<{ 1534 - time: string; 1535 - averageResponseTime: number; 1536 - count: number; 1537 - }>; 1538 - 1539 - // For 15-minute intervals, we'll skip P95 calculation to improve performance 1540 - latencyOverTime = latencyOverTimeRaw.map((intervalData) => ({ 1541 - time: intervalData.time, 1542 - averageResponseTime: intervalData.averageResponseTime, 1543 - p95: null, // Skip P95 for better performance with high granularity 1544 - count: intervalData.count, 1545 - })); 1546 - } else if (days <= 7) { 1547 - // Hourly latency data for 7 days (excluding stats) 1548 - const latencyOverTimeRaw = this.db 1549 - .query( 1550 - ` 1551 - SELECT 1552 - strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')) as time, 1553 - AVG(response_time) as averageResponseTime, 1554 - COUNT(*) as count 1555 - FROM request_analytics 1556 - WHERE timestamp > ? AND response_time IS NOT NULL AND endpoint != '/stats' 1557 - GROUP BY strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')) 1558 - ORDER BY time ASC 1559 - `, 1560 - ) 1561 - .all(cutoffTime) as Array<{ 1562 - time: string; 1563 - averageResponseTime: number; 1564 - count: number; 1565 - }>; 1566 - 1567 - latencyOverTime = latencyOverTimeRaw.map((hourData) => ({ 1568 - time: hourData.time, 1569 - averageResponseTime: hourData.averageResponseTime, 1570 - p95: null, // Skip P95 for better performance 1571 - count: hourData.count, 1572 - })); 1573 - } else { 1574 - // 4-hour intervals for longer periods (excluding stats) 1575 - const latencyOverTimeRaw = this.db 1576 - .query( 1577 - ` 1578 - SELECT 1579 - strftime('%Y-%m-%d ', datetime(timestamp / 1000, 'unixepoch')) || 1580 - CASE 1581 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 4 THEN '00:00' 1582 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 8 THEN '04:00' 1583 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 12 THEN '08:00' 1584 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 16 THEN '12:00' 1585 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 20 THEN '16:00' 1586 - ELSE '20:00' 1587 - END as time, 1588 - AVG(response_time) as averageResponseTime, 1589 - COUNT(*) as count 1590 - FROM request_analytics 1591 - WHERE timestamp > ? AND response_time IS NOT NULL AND endpoint != '/stats' 1592 - GROUP BY strftime('%Y-%m-%d ', datetime(timestamp / 1000, 'unixepoch')) || 1593 - CASE 1594 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 4 THEN '00:00' 1595 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 8 THEN '04:00' 1596 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 12 THEN '08:00' 1597 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 16 THEN '12:00' 1598 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 20 THEN '16:00' 1599 - ELSE '20:00' 1600 - END 1601 - ORDER BY time ASC 1602 - `, 1603 - ) 1604 - .all(cutoffTime) as Array<{ 1605 - time: string; 1606 - averageResponseTime: number; 1607 - count: number; 1608 - }>; 1609 - 1610 - latencyOverTime = latencyOverTimeRaw.map((intervalData) => ({ 1611 - time: intervalData.time, 1612 - averageResponseTime: intervalData.averageResponseTime, 1613 - p95: null, // Skip P95 for better performance 1614 - count: intervalData.count, 1615 - })); 1616 - } 1426 + const latencyOverTime = latencyOverTimeRaw.map((r) => ({ 1427 + time: r.time, 1428 + averageResponseTime: r.count > 0 ? r.totalTime / r.count : 0, 1429 + p95: null as number | null, 1430 + count: r.count, 1431 + })); 1617 1432 1618 1433 // Performance Metrics 1434 + const totalCount = totalResult.count ?? 0; 1619 1435 const errorRequests = statusResults 1620 1436 .filter((s) => s.status >= 400) 1621 1437 .reduce((sum, s) => sum + s.count, 0); 1622 - const errorRate = 1623 - totalResult.count > 0 ? (errorRequests / totalResult.count) * 100 : 0; 1438 + const errorRate = totalCount > 0 ? (errorRequests / totalCount) * 100 : 0; 1624 1439 1625 1440 // Calculate throughput (requests per hour) 1626 1441 const timeSpanHours = days * 24; 1627 - const throughput = totalResult.count / timeSpanHours; 1442 + const throughput = totalCount / timeSpanHours; 1628 1443 1629 - // Calculate APDEX score (Application Performance Index) 1630 - // Satisfied: <= 100ms, Tolerating: <= 400ms, Frustrated: > 400ms 1631 - const satisfiedCount = sortedTimes.filter((t) => t <= 100).length; 1632 - const toleratingCount = sortedTimes.filter( 1633 - (t) => t > 100 && t <= 400, 1634 - ).length; 1635 - const apdex = 1636 - totalWithResponseTime > 0 1637 - ? (satisfiedCount + toleratingCount * 0.5) / totalWithResponseTime 1638 - : 0; 1444 + // APDEX not available with bucket data (need raw response times) 1445 + const apdex = 0; 1639 1446 1640 1447 // Calculate cache hit rate (redirects vs data endpoints) 1641 1448 const redirectRequests = requestsByEndpoint ··· 1652 1459 ? (redirectRequests / (redirectRequests + dataRequests)) * 100 1653 1460 : 0; 1654 1461 1655 - // Simulate uptime (would need actual monitoring data) 1656 - const uptime = Math.max(0, 100 - errorRate * 2); // Simple approximation 1462 + const uptime = Math.max(0, 100 - errorRate * 2); 1657 1463 1658 - // Peak traffic analysis (excluding stats) 1464 + // Peak traffic analysis from bucket table 1659 1465 const peakHourData = this.db 1660 1466 .query( 1661 1467 ` 1662 - SELECT 1663 - strftime('%H:00', datetime(timestamp / 1000, 'unixepoch')) as hour, 1664 - COUNT(*) as count 1665 - FROM request_analytics 1666 - WHERE timestamp > ? AND endpoint != '/stats' 1667 - GROUP BY strftime('%H:00', datetime(timestamp / 1000, 'unixepoch')) 1468 + SELECT 1469 + strftime('%H:00', datetime(bucket, 'unixepoch')) as hour, 1470 + SUM(hits) as count 1471 + FROM ${table} 1472 + WHERE bucket >= ? AND endpoint != '/stats' 1473 + GROUP BY strftime('%H:00', datetime(bucket, 'unixepoch')) 1668 1474 ORDER BY count DESC 1669 1475 LIMIT 1 1670 1476 `, 1671 1477 ) 1672 - .get(cutoffTime) as { hour: string; count: number } | null; 1478 + .get(alignedCutoff) as { hour: string; count: number } | null; 1673 1479 1674 1480 const peakDayData = this.db 1675 1481 .query( 1676 1482 ` 1677 - SELECT 1678 - DATE(timestamp / 1000, 'unixepoch') as day, 1679 - COUNT(*) as count 1680 - FROM request_analytics 1681 - WHERE timestamp > ? AND endpoint != '/stats' 1682 - GROUP BY DATE(timestamp / 1000, 'unixepoch') 1483 + SELECT 1484 + DATE(bucket, 'unixepoch') as day, 1485 + SUM(hits) as count 1486 + FROM ${table} 1487 + WHERE bucket >= ? AND endpoint != '/stats' 1488 + GROUP BY DATE(bucket, 'unixepoch') 1683 1489 ORDER BY count DESC 1684 1490 LIMIT 1 1685 1491 `, 1686 1492 ) 1687 - .get(cutoffTime) as { day: string; count: number } | null; 1493 + .get(alignedCutoff) as { day: string; count: number } | null; 1688 1494 1689 - // Traffic Overview - detailed route breakdown over time 1690 - let trafficOverview: Array<{ 1495 + // Traffic Overview from bucket table 1496 + const trafficRaw = this.db 1497 + .query( 1498 + ` 1499 + SELECT 1500 + datetime(bucket, 'unixepoch') as time, 1501 + endpoint, 1502 + SUM(hits) as count 1503 + FROM ${table} 1504 + WHERE bucket >= ? AND endpoint != '/stats' 1505 + GROUP BY bucket, endpoint 1506 + ORDER BY bucket ASC 1507 + `, 1508 + ) 1509 + .all(alignedCutoff) as Array<{ 1691 1510 time: string; 1692 - routes: Record<string, number>; 1693 - total: number; 1511 + endpoint: string; 1512 + count: number; 1694 1513 }>; 1695 1514 1696 - if (days === 1) { 1697 - // Hourly route breakdown for last 24 hours 1698 - const trafficRaw = this.db 1699 - .query( 1700 - ` 1701 - SELECT 1702 - strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')) as time, 1703 - endpoint, 1704 - COUNT(*) as count 1705 - FROM request_analytics 1706 - WHERE timestamp > ? AND endpoint != '/stats' 1707 - GROUP BY strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')), endpoint 1708 - ORDER BY time ASC 1709 - `, 1710 - ) 1711 - .all(cutoffTime) as Array<{ 1712 - time: string; 1713 - endpoint: string; 1714 - count: number; 1715 - }>; 1716 - 1717 - // Group by time and create route breakdown 1718 - const timeGroups: Record<string, Record<string, number>> = {}; 1719 - for (const row of trafficRaw) { 1720 - if (!timeGroups[row.time]) { 1721 - timeGroups[row.time] = {}; 1722 - } 1723 - 1724 - // Apply same grouping logic as endpoints 1725 - let groupKey: string; 1726 - const endpoint = row.endpoint; 1727 - 1728 - if (endpoint === "/" || endpoint === "/dashboard") { 1729 - groupKey = "Dashboard"; 1730 - } else if (endpoint === "/health") { 1731 - groupKey = "Health Check"; 1732 - } else if (endpoint === "/swagger" || endpoint.startsWith("/swagger")) { 1733 - groupKey = "API Documentation"; 1734 - } else if (endpoint === "/emojis") { 1735 - groupKey = "Emoji List"; 1736 - } else if (endpoint.match(/^\/emojis\/[^/]+$/)) { 1737 - groupKey = "Emoji Data"; 1738 - } else if (endpoint.match(/^\/emojis\/[^/]+\/r$/)) { 1739 - groupKey = "Emoji Redirects"; 1740 - } else if (endpoint.match(/^\/users\/[^/]+$/)) { 1741 - groupKey = "User Data"; 1742 - } else if (endpoint.match(/^\/users\/[^/]+\/r$/)) { 1743 - groupKey = "User Redirects"; 1744 - } else if (endpoint.match(/^\/users\/[^/]+\/purge$/)) { 1745 - groupKey = "Cache Management"; 1746 - } else if (endpoint === "/reset") { 1747 - groupKey = "Cache Management"; 1748 - } else { 1749 - // For any other endpoints, try to categorize them 1750 - if (endpoint.includes("/users/") && endpoint.includes("/r")) { 1751 - groupKey = "User Redirects"; 1752 - } else if (endpoint.includes("/users/")) { 1753 - groupKey = "User Data"; 1754 - } else if (endpoint.includes("/emojis/") && endpoint.includes("/r")) { 1755 - groupKey = "Emoji Redirects"; 1756 - } else if (endpoint.includes("/emojis/")) { 1757 - groupKey = "Emoji Data"; 1758 - } else { 1759 - groupKey = "Other"; 1760 - } 1761 - } 1762 - 1763 - const group = timeGroups[row.time]; 1764 - 1765 - if (group) { 1766 - group[groupKey] = (group[groupKey] || 0) + row.count; 1767 - } 1768 - } 1769 - 1770 - trafficOverview = Object.entries(timeGroups) 1771 - .map(([time, routes]) => ({ 1772 - time, 1773 - routes, 1774 - total: Object.values(routes).reduce((sum, count) => sum + count, 0), 1775 - })) 1776 - .sort((a, b) => a.time.localeCompare(b.time)); 1777 - } else if (days <= 7) { 1778 - // 4-hour intervals for 7 days 1779 - const trafficRaw = this.db 1780 - .query( 1781 - ` 1782 - SELECT 1783 - strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')) as hour, 1784 - endpoint, 1785 - COUNT(*) as count 1786 - FROM request_analytics 1787 - WHERE timestamp > ? AND endpoint != '/stats' 1788 - GROUP BY strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')), endpoint 1789 - ORDER BY hour ASC 1790 - `, 1791 - ) 1792 - .all(cutoffTime) as Array<{ 1793 - hour: string; 1794 - endpoint: string; 1795 - count: number; 1796 - }>; 1797 - 1798 - // Group into 4-hour intervals 1799 - const intervalGroups: Record<string, Record<string, number>> = {}; 1800 - for (const row of trafficRaw) { 1801 - const hourStr = row.hour?.split(" ")[1]?.split(":")[0]; 1802 - const hour = hourStr ? parseInt(hourStr, 10) : 0; 1803 - const intervalHour = Math.floor(hour / 4) * 4; 1804 - const intervalTime = 1805 - row.hour.split(" ")[0] + 1806 - ` ${intervalHour.toString().padStart(2, "0")}:00`; 1807 - 1808 - if (!intervalGroups[intervalTime]) { 1809 - intervalGroups[intervalTime] = {}; 1810 - } 1811 - 1812 - // Apply same grouping logic 1813 - let groupKey: string; 1814 - const endpoint = row.endpoint; 1815 - 1816 - if (endpoint === "/" || endpoint === "/dashboard") { 1817 - groupKey = "Dashboard"; 1818 - } else if (endpoint === "/health") { 1819 - groupKey = "Health Check"; 1820 - } else if (endpoint === "/swagger" || endpoint.startsWith("/swagger")) { 1821 - groupKey = "API Documentation"; 1822 - } else if (endpoint === "/emojis") { 1823 - groupKey = "Emoji List"; 1824 - } else if (endpoint.match(/^\/emojis\/[^/]+$/)) { 1825 - groupKey = "Emoji Data"; 1826 - } else if (endpoint.match(/^\/emojis\/[^/]+\/r$/)) { 1827 - groupKey = "Emoji Redirects"; 1828 - } else if (endpoint.match(/^\/users\/[^/]+$/)) { 1829 - groupKey = "User Data"; 1830 - } else if (endpoint.match(/^\/users\/[^/]+\/r$/)) { 1831 - groupKey = "User Redirects"; 1832 - } else if (endpoint.match(/^\/users\/[^/]+\/purge$/)) { 1833 - groupKey = "Cache Management"; 1834 - } else if (endpoint === "/reset") { 1835 - groupKey = "Cache Management"; 1836 - } else { 1837 - // For any other endpoints, try to categorize them 1838 - if (endpoint.includes("/users/") && endpoint.includes("/r")) { 1839 - groupKey = "User Redirects"; 1840 - } else if (endpoint.includes("/users/")) { 1841 - groupKey = "User Data"; 1842 - } else if (endpoint.includes("/emojis/") && endpoint.includes("/r")) { 1843 - groupKey = "Emoji Redirects"; 1844 - } else if (endpoint.includes("/emojis/")) { 1845 - groupKey = "Emoji Data"; 1846 - } else { 1847 - groupKey = "Other"; 1848 - } 1849 - } 1850 - 1851 - intervalGroups[intervalTime][groupKey] = 1852 - (intervalGroups[intervalTime][groupKey] || 0) + row.count; 1515 + // Group by time and create route breakdown 1516 + const timeGroups: Record<string, Record<string, number>> = {}; 1517 + for (const row of trafficRaw) { 1518 + if (!timeGroups[row.time]) { 1519 + timeGroups[row.time] = {}; 1853 1520 } 1854 1521 1855 - trafficOverview = Object.entries(intervalGroups) 1856 - .map(([time, routes]) => ({ 1857 - time, 1858 - routes, 1859 - total: Object.values(routes).reduce((sum, count) => sum + count, 0), 1860 - })) 1861 - .sort((a, b) => a.time.localeCompare(b.time)); 1862 - } else { 1863 - // Daily breakdown for longer periods 1864 - const trafficRaw = this.db 1865 - .query( 1866 - ` 1867 - SELECT 1868 - DATE(timestamp / 1000, 'unixepoch') as time, 1869 - endpoint, 1870 - COUNT(*) as count 1871 - FROM request_analytics 1872 - WHERE timestamp > ? AND endpoint != '/stats' 1873 - GROUP BY DATE(timestamp / 1000, 'unixepoch'), endpoint 1874 - ORDER BY time ASC 1875 - `, 1876 - ) 1877 - .all(cutoffTime) as Array<{ 1878 - time: string; 1879 - endpoint: string; 1880 - count: number; 1881 - }>; 1522 + const groupKey = this.groupEndpoint(row.endpoint); 1523 + const group = timeGroups[row.time]; 1882 1524 1883 - // Group by day 1884 - const dayGroups: Record<string, Record<string, number>> = {}; 1885 - for (const row of trafficRaw) { 1886 - if (!dayGroups[row.time]) { 1887 - dayGroups[row.time] = {}; 1888 - } 1889 - 1890 - // Apply same grouping logic 1891 - let groupKey: string; 1892 - const endpoint = row.endpoint; 1893 - 1894 - if (endpoint === "/" || endpoint === "/dashboard") { 1895 - groupKey = "Dashboard"; 1896 - } else if (endpoint === "/health") { 1897 - groupKey = "Health Check"; 1898 - } else if (endpoint === "/swagger" || endpoint.startsWith("/swagger")) { 1899 - groupKey = "API Documentation"; 1900 - } else if (endpoint === "/emojis") { 1901 - groupKey = "Emoji List"; 1902 - } else if (endpoint.match(/^\/emojis\/[^/]+$/)) { 1903 - groupKey = "Emoji Data"; 1904 - } else if (endpoint.match(/^\/emojis\/[^/]+\/r$/)) { 1905 - groupKey = "Emoji Redirects"; 1906 - } else if (endpoint.match(/^\/users\/[^/]+$/)) { 1907 - groupKey = "User Data"; 1908 - } else if (endpoint.match(/^\/users\/[^/]+\/r$/)) { 1909 - groupKey = "User Redirects"; 1910 - } else if (endpoint.match(/^\/users\/[^/]+\/purge$/)) { 1911 - groupKey = "Cache Management"; 1912 - } else if (endpoint === "/reset") { 1913 - groupKey = "Cache Management"; 1914 - } else { 1915 - // For any other endpoints, try to categorize them 1916 - if (endpoint.includes("/users/") && endpoint.includes("/r")) { 1917 - groupKey = "User Redirects"; 1918 - } else if (endpoint.includes("/users/")) { 1919 - groupKey = "User Data"; 1920 - } else if (endpoint.includes("/emojis/") && endpoint.includes("/r")) { 1921 - groupKey = "Emoji Redirects"; 1922 - } else if (endpoint.includes("/emojis/")) { 1923 - groupKey = "Emoji Data"; 1924 - } else { 1925 - groupKey = "Other"; 1926 - } 1927 - } 1928 - const group = dayGroups[row.time]; 1929 - if (group) { 1930 - group[groupKey] = (group[groupKey] || 0) + row.count; 1931 - } 1525 + if (group) { 1526 + group[groupKey] = (group[groupKey] || 0) + row.count; 1932 1527 } 1933 - 1934 - trafficOverview = Object.entries(dayGroups) 1935 - .map(([time, routes]) => ({ 1936 - time, 1937 - routes, 1938 - total: Object.values(routes).reduce((sum, count) => sum + count, 0), 1939 - })) 1940 - .sort((a, b) => a.time.localeCompare(b.time)); 1941 1528 } 1942 1529 1530 + const trafficOverview = Object.entries(timeGroups) 1531 + .map(([time, routes]) => ({ 1532 + time, 1533 + routes, 1534 + total: Object.values(routes).reduce((sum, count) => sum + count, 0), 1535 + })) 1536 + .sort((a, b) => a.time.localeCompare(b.time)); 1537 + 1943 1538 const result = { 1944 - totalRequests: totalResult.count, 1539 + totalRequests: totalCount, 1945 1540 requestsByEndpoint: requestsByEndpoint, 1946 1541 requestsByStatus: statusResults, 1947 1542 requestsByDay: timeResults, 1948 - averageResponseTime: avgResponseResult.avg, 1543 + averageResponseTime: averageResponseTime, 1949 1544 topUserAgents: topUserAgents, 1950 1545 latencyAnalytics: { 1951 1546 percentiles, ··· 1968 1563 }, 1969 1564 dashboardMetrics: { 1970 1565 statsRequests: statsResult.count, 1971 - totalWithStats: totalResult.count + statsResult.count, 1566 + totalWithStats: totalCount + statsResult.count, 1972 1567 }, 1973 1568 trafficOverview, 1974 1569 }; ··· 1989 1584 averageResponseTime: number | null; 1990 1585 uptime: number; 1991 1586 }> { 1992 - // Check cache first 1993 1587 const cacheKey = `essential_${days}`; 1994 1588 const cached = this.typedAnalyticsCache.getEssentialStatsData(cacheKey); 1995 1589 ··· 1997 1591 return cached; 1998 1592 } 1999 1593 2000 - const cutoffTime = Date.now() - days * 24 * 60 * 60 * 1000; 1594 + const { table, bucketSize } = this.selectBucketTable(days); 1595 + const cutoffBucket = Math.floor(Date.now() / 1000) - days * 24 * 60 * 60; 1596 + const alignedCutoff = cutoffBucket - (cutoffBucket % bucketSize); 2001 1597 2002 - // Total requests (excluding stats endpoint) - fastest query 1598 + // Total requests from bucket table 2003 1599 const totalResult = this.db 2004 1600 .query( 2005 - "SELECT COUNT(*) as count FROM request_analytics WHERE timestamp > ? AND endpoint != '/stats'", 1601 + `SELECT SUM(hits) as count FROM ${table} WHERE bucket >= ? AND endpoint != '/stats'`, 2006 1602 ) 2007 - .get(cutoffTime) as { count: number }; 1603 + .get(alignedCutoff) as { count: number | null }; 2008 1604 2009 - // Average response time (excluding stats) - simple query 1605 + // Average response time from bucket table 2010 1606 const avgResponseResult = this.db 2011 1607 .query( 2012 - "SELECT AVG(response_time) as avg FROM request_analytics WHERE timestamp > ? AND response_time IS NOT NULL AND endpoint != '/stats'", 1608 + `SELECT SUM(total_response_time) as totalTime, SUM(hits) as totalHits FROM ${table} WHERE bucket >= ? AND endpoint != '/stats'`, 2013 1609 ) 2014 - .get(cutoffTime) as { avg: number | null }; 1610 + .get(alignedCutoff) as { totalTime: number | null; totalHits: number | null }; 2015 1611 2016 - // Simple error rate calculation for uptime 2017 - const errorRequests = this.db 1612 + // Error rate from bucket table 1613 + const errorResult = this.db 2018 1614 .query( 2019 - "SELECT COUNT(*) as count FROM request_analytics WHERE timestamp > ? AND status_code >= 400 AND endpoint != '/stats'", 1615 + `SELECT SUM(hits) as count FROM ${table} WHERE bucket >= ? AND status_code >= 400 AND endpoint != '/stats'`, 2020 1616 ) 2021 - .get(cutoffTime) as { count: number }; 1617 + .get(alignedCutoff) as { count: number | null }; 2022 1618 2023 - const errorRate = 2024 - totalResult.count > 0 2025 - ? (errorRequests.count / totalResult.count) * 100 2026 - : 0; 2027 - const uptime = Math.max(0, 100 - errorRate * 2); // Simple approximation 1619 + const totalCount = totalResult.count ?? 0; 1620 + const errorRate = totalCount > 0 ? ((errorResult.count ?? 0) / totalCount) * 100 : 0; 1621 + const uptime = Math.max(0, 100 - errorRate * 2); 2028 1622 2029 1623 const result = { 2030 - totalRequests: totalResult.count, 2031 - averageResponseTime: avgResponseResult.avg, 1624 + totalRequests: totalCount, 1625 + averageResponseTime: 1626 + avgResponseResult.totalHits && avgResponseResult.totalHits > 0 1627 + ? (avgResponseResult.totalTime ?? 0) / avgResponseResult.totalHits 1628 + : null, 2032 1629 uptime: uptime, 2033 1630 }; 2034 1631 2035 - // Cache the result 2036 1632 this.typedAnalyticsCache.setEssentialStatsData(cacheKey, result); 2037 1633 2038 1634 return result; ··· 2056 1652 count: number; 2057 1653 }>; 2058 1654 }> { 2059 - // Check cache first 2060 1655 const cacheKey = `charts_${days}`; 2061 1656 const cached = this.typedAnalyticsCache.getChartData(cacheKey); 2062 1657 ··· 2064 1659 return cached; 2065 1660 } 2066 1661 2067 - const cutoffTime = Date.now() - days * 24 * 60 * 60 * 1000; 1662 + const { table, bucketSize } = this.selectBucketTable(days); 1663 + const cutoffBucket = Math.floor(Date.now() / 1000) - days * 24 * 60 * 60; 1664 + const alignedCutoff = cutoffBucket - (cutoffBucket % bucketSize); 2068 1665 2069 - // Reuse the existing time logic from getAnalytics 2070 - let timeResults: Array<{ 1666 + // Requests over time from bucket table 1667 + const timeResultsRaw = this.db 1668 + .query( 1669 + ` 1670 + SELECT 1671 + datetime(bucket, 'unixepoch') as date, 1672 + SUM(hits) as count, 1673 + SUM(total_response_time) as totalTime, 1674 + SUM(hits) as totalHits 1675 + FROM ${table} 1676 + WHERE bucket >= ? AND endpoint != '/stats' 1677 + GROUP BY bucket 1678 + ORDER BY bucket ASC 1679 + `, 1680 + ) 1681 + .all(alignedCutoff) as Array<{ 2071 1682 date: string; 2072 1683 count: number; 2073 - averageResponseTime: number; 2074 - }>; 2075 - 2076 - if (days === 1) { 2077 - // 15-minute intervals for last 24 hours (excluding stats) 2078 - const intervalResultsRaw = this.db 2079 - .query( 2080 - ` 2081 - SELECT 2082 - strftime('%Y-%m-%d %H:', datetime(timestamp / 1000, 'unixepoch')) || 2083 - CASE 2084 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 15 THEN '00' 2085 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 30 THEN '15' 2086 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 45 THEN '30' 2087 - ELSE '45' 2088 - END as date, 2089 - COUNT(*) as count, 2090 - AVG(response_time) as averageResponseTime 2091 - FROM request_analytics 2092 - WHERE timestamp > ? AND endpoint != '/stats' 2093 - GROUP BY strftime('%Y-%m-%d %H:', datetime(timestamp / 1000, 'unixepoch')) || 2094 - CASE 2095 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 15 THEN '00' 2096 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 30 THEN '15' 2097 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 45 THEN '30' 2098 - ELSE '45' 2099 - END 2100 - ORDER BY date ASC 2101 - `, 2102 - ) 2103 - .all(cutoffTime) as Array<{ 2104 - date: string; 2105 - count: number; 2106 - averageResponseTime: number | null; 2107 - }>; 2108 - 2109 - timeResults = intervalResultsRaw.map((h) => ({ 2110 - date: h.date, 2111 - count: h.count, 2112 - averageResponseTime: h.averageResponseTime ?? 0, 2113 - })); 2114 - } else if (days <= 7) { 2115 - // Hourly data for 7 days (excluding stats) 2116 - const hourResultsRaw = this.db 2117 - .query( 2118 - ` 2119 - SELECT 2120 - strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')) as date, 2121 - COUNT(*) as count, 2122 - AVG(response_time) as averageResponseTime 2123 - FROM request_analytics 2124 - WHERE timestamp > ? AND endpoint != '/stats' 2125 - GROUP BY strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')) 2126 - ORDER BY date ASC 2127 - `, 2128 - ) 2129 - .all(cutoffTime) as Array<{ 2130 - date: string; 2131 - count: number; 2132 - averageResponseTime: number | null; 2133 - }>; 2134 - 2135 - timeResults = hourResultsRaw.map((h) => ({ 2136 - date: h.date, 2137 - count: h.count, 2138 - averageResponseTime: h.averageResponseTime ?? 0, 2139 - })); 2140 - } else { 2141 - // 4-hour intervals for longer periods (excluding stats) 2142 - const intervalResultsRaw = this.db 2143 - .query( 2144 - ` 2145 - SELECT 2146 - strftime('%Y-%m-%d ', datetime(timestamp / 1000, 'unixepoch')) || 2147 - CASE 2148 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 4 THEN '00:00' 2149 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 8 THEN '04:00' 2150 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 12 THEN '08:00' 2151 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 16 THEN '12:00' 2152 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 20 THEN '16:00' 2153 - ELSE '20:00' 2154 - END as date, 2155 - COUNT(*) as count, 2156 - AVG(response_time) as averageResponseTime 2157 - FROM request_analytics 2158 - WHERE timestamp > ? AND endpoint != '/stats' 2159 - GROUP BY strftime('%Y-%m-%d ', datetime(timestamp / 1000, 'unixepoch')) || 2160 - CASE 2161 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 4 THEN '00:00' 2162 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 8 THEN '04:00' 2163 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 12 THEN '08:00' 2164 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 16 THEN '12:00' 2165 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 20 THEN '16:00' 2166 - ELSE '20:00' 2167 - END 2168 - ORDER BY date ASC 2169 - `, 2170 - ) 2171 - .all(cutoffTime) as Array<{ 2172 - date: string; 2173 - count: number; 2174 - averageResponseTime: number | null; 2175 - }>; 2176 - 2177 - timeResults = intervalResultsRaw.map((d) => ({ 2178 - date: d.date, 2179 - count: d.count, 2180 - averageResponseTime: d.averageResponseTime ?? 0, 2181 - })); 2182 - } 2183 - 2184 - // Latency over time data (reuse from getAnalytics) 2185 - let latencyOverTime: Array<{ 2186 - time: string; 2187 - averageResponseTime: number; 2188 - p95: number | null; 2189 - count: number; 1684 + totalTime: number; 1685 + totalHits: number; 2190 1686 }>; 2191 1687 2192 - if (days === 1) { 2193 - const latencyOverTimeRaw = this.db 2194 - .query( 2195 - ` 2196 - SELECT 2197 - strftime('%Y-%m-%d %H:', datetime(timestamp / 1000, 'unixepoch')) || 2198 - CASE 2199 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 15 THEN '00' 2200 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 30 THEN '15' 2201 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 45 THEN '30' 2202 - ELSE '45' 2203 - END as time, 2204 - AVG(response_time) as averageResponseTime, 2205 - COUNT(*) as count 2206 - FROM request_analytics 2207 - WHERE timestamp > ? AND response_time IS NOT NULL AND endpoint != '/stats' 2208 - GROUP BY strftime('%Y-%m-%d %H:', datetime(timestamp / 1000, 'unixepoch')) || 2209 - CASE 2210 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 15 THEN '00' 2211 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 30 THEN '15' 2212 - WHEN CAST(strftime('%M', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 45 THEN '30' 2213 - ELSE '45' 2214 - END 2215 - ORDER BY time ASC 2216 - `, 2217 - ) 2218 - .all(cutoffTime) as Array<{ 2219 - time: string; 2220 - averageResponseTime: number; 2221 - count: number; 2222 - }>; 2223 - 2224 - latencyOverTime = latencyOverTimeRaw.map((intervalData) => ({ 2225 - time: intervalData.time, 2226 - averageResponseTime: intervalData.averageResponseTime, 2227 - p95: null, // Skip P95 for better performance 2228 - count: intervalData.count, 2229 - })); 2230 - } else if (days <= 7) { 2231 - const latencyOverTimeRaw = this.db 2232 - .query( 2233 - ` 2234 - SELECT 2235 - strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')) as time, 2236 - AVG(response_time) as averageResponseTime, 2237 - COUNT(*) as count 2238 - FROM request_analytics 2239 - WHERE timestamp > ? AND response_time IS NOT NULL AND endpoint != '/stats' 2240 - GROUP BY strftime('%Y-%m-%d %H:00', datetime(timestamp / 1000, 'unixepoch')) 2241 - ORDER BY time ASC 2242 - `, 2243 - ) 2244 - .all(cutoffTime) as Array<{ 2245 - time: string; 2246 - averageResponseTime: number; 2247 - count: number; 2248 - }>; 2249 - 2250 - latencyOverTime = latencyOverTimeRaw.map((hourData) => ({ 2251 - time: hourData.time, 2252 - averageResponseTime: hourData.averageResponseTime, 2253 - p95: null, // Skip P95 for better performance 2254 - count: hourData.count, 2255 - })); 2256 - } else { 2257 - const latencyOverTimeRaw = this.db 2258 - .query( 2259 - ` 2260 - SELECT 2261 - strftime('%Y-%m-%d ', datetime(timestamp / 1000, 'unixepoch')) || 2262 - CASE 2263 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 4 THEN '00:00' 2264 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 8 THEN '04:00' 2265 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 12 THEN '08:00' 2266 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 16 THEN '12:00' 2267 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 20 THEN '16:00' 2268 - ELSE '20:00' 2269 - END as time, 2270 - AVG(response_time) as averageResponseTime, 2271 - COUNT(*) as count 2272 - FROM request_analytics 2273 - WHERE timestamp > ? AND response_time IS NOT NULL AND endpoint != '/stats' 2274 - GROUP BY strftime('%Y-%m-%d ', datetime(timestamp / 1000, 'unixepoch')) || 2275 - CASE 2276 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 4 THEN '00:00' 2277 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 8 THEN '04:00' 2278 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 12 THEN '08:00' 2279 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 16 THEN '12:00' 2280 - WHEN CAST(strftime('%H', datetime(timestamp / 1000, 'unixepoch')) AS INTEGER) < 20 THEN '16:00' 2281 - ELSE '20:00' 2282 - END 2283 - ORDER BY time ASC 2284 - `, 2285 - ) 2286 - .all(cutoffTime) as Array<{ 2287 - time: string; 2288 - averageResponseTime: number; 2289 - count: number; 2290 - }>; 1688 + const requestsByDay = timeResultsRaw.map((r) => ({ 1689 + date: r.date, 1690 + count: r.count, 1691 + averageResponseTime: r.totalHits > 0 ? r.totalTime / r.totalHits : 0, 1692 + })); 2291 1693 2292 - latencyOverTime = latencyOverTimeRaw.map((intervalData) => ({ 2293 - time: intervalData.time, 2294 - averageResponseTime: intervalData.averageResponseTime, 2295 - p95: null, // Skip P95 for better performance 2296 - count: intervalData.count, 2297 - })); 2298 - } 1694 + // Latency over time (same query, different format) 1695 + const latencyOverTime = timeResultsRaw.map((r) => ({ 1696 + time: r.date, 1697 + averageResponseTime: r.totalHits > 0 ? r.totalTime / r.totalHits : 0, 1698 + p95: null as number | null, 1699 + count: r.count, 1700 + })); 2299 1701 2300 1702 const result = { 2301 - requestsByDay: timeResults, 2302 - latencyOverTime: latencyOverTime, 1703 + requestsByDay, 1704 + latencyOverTime, 2303 1705 }; 2304 1706 2305 - // Cache the result 2306 1707 this.typedAnalyticsCache.setChartData(cacheKey, result); 2307 1708 2308 1709 return result; 2309 1710 } 2310 1711 2311 1712 /** 2312 - * Gets user agents data only (slowest loading) 2313 - * @param days Number of days to look back (default: 7) 1713 + * Gets user agents data from cumulative stats table 1714 + * @param _days Unused - user_agent_stats is cumulative 2314 1715 * @returns User agents data 2315 1716 */ 2316 1717 async getUserAgents( 2317 - days: number = 7, 1718 + _days: number = 7, 2318 1719 ): Promise<Array<{ userAgent: string; count: number }>> { 2319 - // Check cache first 2320 - const cacheKey = `useragents_${days}`; 1720 + const cacheKey = "useragents_all"; 2321 1721 const cached = this.typedAnalyticsCache.getUserAgentData(cacheKey); 2322 1722 2323 1723 if (cached) { 2324 1724 return cached; 2325 1725 } 2326 1726 2327 - const cutoffTime = Date.now() - days * 24 * 60 * 60 * 1000; 2328 - 2329 - // Top user agents (raw strings, excluding stats) - optimized with index hint 1727 + // Query user_agent_stats table directly (cumulative, no time filtering) 2330 1728 const topUserAgents = this.db 2331 1729 .query( 2332 1730 ` 2333 - SELECT user_agent as userAgent, COUNT(*) as count 2334 - FROM request_analytics INDEXED BY idx_request_analytics_user_agent 2335 - WHERE timestamp > ? AND user_agent IS NOT NULL AND endpoint != '/stats' 2336 - GROUP BY user_agent 2337 - ORDER BY count DESC 1731 + SELECT user_agent as userAgent, hits as count 1732 + FROM user_agent_stats 1733 + WHERE user_agent IS NOT NULL 1734 + ORDER BY hits DESC 2338 1735 LIMIT 50 2339 1736 `, 2340 1737 ) 2341 - .all(cutoffTime) as Array<{ userAgent: string; count: number }>; 1738 + .all() as Array<{ userAgent: string; count: number }>; 2342 1739 2343 - // Cache the result 2344 1740 this.typedAnalyticsCache.setUserAgentData(cacheKey, topUserAgents); 2345 1741 2346 1742 return topUserAgents;
+200
src/migrations/bucketAnalyticsMigration.ts
··· 1 + import type { Database } from "bun:sqlite"; 2 + import type { Migration } from "./types"; 3 + 4 + /** 5 + * Migration to convert raw request_analytics to bucketed time-series tables. 6 + * This dramatically reduces storage and improves query performance. 7 + * 8 + * New tables: 9 + * - traffic_10min: 10-minute buckets, pruned after 24h (high resolution) 10 + * - traffic_hourly: Hourly buckets (medium resolution) 11 + * - traffic_daily: Daily buckets (long-term storage) 12 + * - user_agent_stats: Aggregate counts per user agent 13 + */ 14 + export const bucketAnalyticsMigration: Migration = { 15 + version: "0.4.0", 16 + description: "Convert to bucketed time-series analytics", 17 + 18 + async up(db: Database): Promise<void> { 19 + console.log("Running bucket analytics migration..."); 20 + 21 + // Create 10-minute traffic table 22 + db.run(` 23 + CREATE TABLE IF NOT EXISTS traffic_10min ( 24 + bucket INTEGER NOT NULL, 25 + endpoint TEXT NOT NULL, 26 + status_code INTEGER NOT NULL, 27 + hits INTEGER NOT NULL DEFAULT 1, 28 + total_response_time INTEGER NOT NULL DEFAULT 0, 29 + PRIMARY KEY (bucket, endpoint, status_code) 30 + ) WITHOUT ROWID 31 + `); 32 + 33 + // Create hourly traffic table 34 + db.run(` 35 + CREATE TABLE IF NOT EXISTS traffic_hourly ( 36 + bucket INTEGER NOT NULL, 37 + endpoint TEXT NOT NULL, 38 + status_code INTEGER NOT NULL, 39 + hits INTEGER NOT NULL DEFAULT 1, 40 + total_response_time INTEGER NOT NULL DEFAULT 0, 41 + PRIMARY KEY (bucket, endpoint, status_code) 42 + ) WITHOUT ROWID 43 + `); 44 + 45 + // Create daily traffic table 46 + db.run(` 47 + CREATE TABLE IF NOT EXISTS traffic_daily ( 48 + bucket INTEGER NOT NULL, 49 + endpoint TEXT NOT NULL, 50 + status_code INTEGER NOT NULL, 51 + hits INTEGER NOT NULL DEFAULT 1, 52 + total_response_time INTEGER NOT NULL DEFAULT 0, 53 + PRIMARY KEY (bucket, endpoint, status_code) 54 + ) WITHOUT ROWID 55 + `); 56 + 57 + // Create user agent stats table 58 + db.run(` 59 + CREATE TABLE IF NOT EXISTS user_agent_stats ( 60 + user_agent TEXT PRIMARY KEY, 61 + hits INTEGER NOT NULL DEFAULT 1, 62 + last_seen INTEGER NOT NULL 63 + ) WITHOUT ROWID 64 + `); 65 + 66 + // Create indexes for time-range queries 67 + db.run( 68 + "CREATE INDEX IF NOT EXISTS idx_traffic_10min_bucket ON traffic_10min(bucket)", 69 + ); 70 + db.run( 71 + "CREATE INDEX IF NOT EXISTS idx_traffic_hourly_bucket ON traffic_hourly(bucket)", 72 + ); 73 + db.run( 74 + "CREATE INDEX IF NOT EXISTS idx_traffic_daily_bucket ON traffic_daily(bucket)", 75 + ); 76 + db.run( 77 + "CREATE INDEX IF NOT EXISTS idx_user_agent_hits ON user_agent_stats(hits DESC)", 78 + ); 79 + 80 + // Migrate existing data from request_analytics 81 + console.log("Migrating existing analytics data to buckets..."); 82 + 83 + const existingData = db 84 + .query( 85 + ` 86 + SELECT 87 + endpoint, 88 + status_code, 89 + user_agent, 90 + timestamp, 91 + response_time 92 + FROM request_analytics 93 + `, 94 + ) 95 + .all() as Array<{ 96 + endpoint: string; 97 + status_code: number; 98 + user_agent: string | null; 99 + timestamp: number; 100 + response_time: number | null; 101 + }>; 102 + 103 + console.log(`Found ${existingData.length} existing records to migrate`); 104 + 105 + // Prepare statements for bulk insert 106 + const insert10min = db.prepare(` 107 + INSERT INTO traffic_10min (bucket, endpoint, status_code, hits, total_response_time) 108 + VALUES (?1, ?2, ?3, 1, ?4) 109 + ON CONFLICT(bucket, endpoint, status_code) DO UPDATE SET 110 + hits = hits + 1, 111 + total_response_time = total_response_time + ?4 112 + `); 113 + 114 + const insertHourly = db.prepare(` 115 + INSERT INTO traffic_hourly (bucket, endpoint, status_code, hits, total_response_time) 116 + VALUES (?1, ?2, ?3, 1, ?4) 117 + ON CONFLICT(bucket, endpoint, status_code) DO UPDATE SET 118 + hits = hits + 1, 119 + total_response_time = total_response_time + ?4 120 + `); 121 + 122 + const insertDaily = db.prepare(` 123 + INSERT INTO traffic_daily (bucket, endpoint, status_code, hits, total_response_time) 124 + VALUES (?1, ?2, ?3, 1, ?4) 125 + ON CONFLICT(bucket, endpoint, status_code) DO UPDATE SET 126 + hits = hits + 1, 127 + total_response_time = total_response_time + ?4 128 + `); 129 + 130 + const insertUserAgent = db.prepare(` 131 + INSERT INTO user_agent_stats (user_agent, hits, last_seen) 132 + VALUES (?1, 1, ?2) 133 + ON CONFLICT(user_agent) DO UPDATE SET 134 + hits = hits + 1, 135 + last_seen = MAX(last_seen, ?2) 136 + `); 137 + 138 + // Process in batches using transactions 139 + const batchSize = 10000; 140 + for (let i = 0; i < existingData.length; i += batchSize) { 141 + const batch = existingData.slice(i, i + batchSize); 142 + 143 + db.transaction(() => { 144 + for (const row of batch) { 145 + const timestampSec = Math.floor(row.timestamp / 1000); 146 + const bucket10min = timestampSec - (timestampSec % 600); 147 + const bucketHour = timestampSec - (timestampSec % 3600); 148 + const bucketDay = timestampSec - (timestampSec % 86400); 149 + const responseTime = row.response_time || 0; 150 + 151 + // Only insert 10min data for last 24 hours 152 + const oneDayAgo = Math.floor(Date.now() / 1000) - 86400; 153 + if (bucket10min >= oneDayAgo) { 154 + insert10min.run( 155 + bucket10min, 156 + row.endpoint, 157 + row.status_code, 158 + responseTime, 159 + ); 160 + } 161 + 162 + insertHourly.run( 163 + bucketHour, 164 + row.endpoint, 165 + row.status_code, 166 + responseTime, 167 + ); 168 + insertDaily.run( 169 + bucketDay, 170 + row.endpoint, 171 + row.status_code, 172 + responseTime, 173 + ); 174 + 175 + if (row.user_agent) { 176 + insertUserAgent.run(row.user_agent, row.timestamp); 177 + } 178 + } 179 + })(); 180 + 181 + console.log( 182 + `Migrated ${Math.min(i + batchSize, existingData.length)}/${existingData.length} records`, 183 + ); 184 + } 185 + 186 + // Drop old table 187 + console.log("Dropping old request_analytics table..."); 188 + db.run("DROP TABLE IF EXISTS request_analytics"); 189 + 190 + // Note: VACUUM cannot run inside a transaction, run manually after migration if needed 191 + console.log("Bucket analytics migration completed (run VACUUM manually to reclaim space)"); 192 + }, 193 + 194 + async down(db: Database): Promise<void> { 195 + db.run("DROP TABLE IF EXISTS traffic_10min"); 196 + db.run("DROP TABLE IF EXISTS traffic_hourly"); 197 + db.run("DROP TABLE IF EXISTS traffic_daily"); 198 + db.run("DROP TABLE IF EXISTS user_agent_stats"); 199 + }, 200 + };
+2
src/migrations/index.ts
··· 1 + import { bucketAnalyticsMigration } from "./bucketAnalyticsMigration"; 1 2 import { endpointGroupingMigration } from "./endpointGroupingMigration"; 2 3 import { logGroupingMigration } from "./logGroupingMigration"; 3 4 import { Migration } from "./types"; ··· 6 7 export const migrations = [ 7 8 endpointGroupingMigration, 8 9 logGroupingMigration, 10 + bucketAnalyticsMigration, 9 11 // Add new migrations here 10 12 ]; 11 13