Add query optimization and reliability improvements
- Consolidate StatsModel queries from 12 to 3 using conditional aggregation - Add input validation to DashboardController (sort columns, dates, priorities) - Combine getCategories/getTypes into single query - Add transaction support to BulkOperationsModel with atomic mode option - Add depth limit (20) to dependency cycle detection to prevent DoS - Add caching to UserModel.getAllGroups() with 5-minute TTL - Improve ticket ID generation with 50 attempts, exponential backoff, and fallback Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
@@ -200,22 +200,76 @@ class StatsModel {
|
||||
/**
|
||||
* Fetch all stats from database (uncached)
|
||||
*
|
||||
* Uses consolidated queries to reduce database round-trips from 12 to 4.
|
||||
*
|
||||
* @return array All dashboard statistics
|
||||
*/
|
||||
private function fetchAllStats(): array {
|
||||
// Query 1: Get all simple counts in one query using conditional aggregation
|
||||
$countsSql = "SELECT
|
||||
SUM(CASE WHEN status IN ('Open', 'Pending', 'In Progress') THEN 1 ELSE 0 END) as open_tickets,
|
||||
SUM(CASE WHEN status = 'Closed' THEN 1 ELSE 0 END) as closed_tickets,
|
||||
SUM(CASE WHEN DATE(created_at) = CURDATE() THEN 1 ELSE 0 END) as created_today,
|
||||
SUM(CASE WHEN YEARWEEK(created_at, 1) = YEARWEEK(CURDATE(), 1) THEN 1 ELSE 0 END) as created_this_week,
|
||||
SUM(CASE WHEN status = 'Closed' AND DATE(updated_at) = CURDATE() THEN 1 ELSE 0 END) as closed_today,
|
||||
SUM(CASE WHEN assigned_to IS NULL AND status != 'Closed' THEN 1 ELSE 0 END) as unassigned,
|
||||
SUM(CASE WHEN priority = 1 AND status != 'Closed' THEN 1 ELSE 0 END) as critical,
|
||||
AVG(CASE WHEN status = 'Closed' AND updated_at > created_at
|
||||
THEN TIMESTAMPDIFF(HOUR, created_at, updated_at) ELSE NULL END) as avg_resolution
|
||||
FROM tickets";
|
||||
|
||||
$countsResult = $this->conn->query($countsSql);
|
||||
$counts = $countsResult->fetch_assoc();
|
||||
|
||||
// Query 2: Get priority, status, and category breakdowns in one query
|
||||
$breakdownSql = "SELECT
|
||||
'priority' as type, CONCAT('P', priority) as label, COUNT(*) as count
|
||||
FROM tickets WHERE status != 'Closed' GROUP BY priority
|
||||
UNION ALL
|
||||
SELECT 'status' as type, status as label, COUNT(*) as count
|
||||
FROM tickets GROUP BY status
|
||||
UNION ALL
|
||||
SELECT 'category' as type, category as label, COUNT(*) as count
|
||||
FROM tickets WHERE status != 'Closed' GROUP BY category";
|
||||
|
||||
$breakdownResult = $this->conn->query($breakdownSql);
|
||||
$byPriority = [];
|
||||
$byStatus = [];
|
||||
$byCategory = [];
|
||||
|
||||
while ($row = $breakdownResult->fetch_assoc()) {
|
||||
switch ($row['type']) {
|
||||
case 'priority':
|
||||
$byPriority[$row['label']] = (int)$row['count'];
|
||||
break;
|
||||
case 'status':
|
||||
$byStatus[$row['label']] = (int)$row['count'];
|
||||
break;
|
||||
case 'category':
|
||||
$byCategory[$row['label']] = (int)$row['count'];
|
||||
break;
|
||||
}
|
||||
}
|
||||
|
||||
// Sort priority keys
|
||||
ksort($byPriority);
|
||||
|
||||
// Query 3: Get assignee stats (requires JOIN, kept separate)
|
||||
$byAssignee = $this->getTicketsByAssignee();
|
||||
|
||||
return [
|
||||
'open_tickets' => $this->getOpenTicketCount(),
|
||||
'closed_tickets' => $this->getClosedTicketCount(),
|
||||
'created_today' => $this->getTicketsCreatedToday(),
|
||||
'created_this_week' => $this->getTicketsCreatedThisWeek(),
|
||||
'closed_today' => $this->getTicketsClosedToday(),
|
||||
'unassigned' => $this->getUnassignedTicketCount(),
|
||||
'critical' => $this->getCriticalTicketCount(),
|
||||
'avg_resolution_hours' => $this->getAverageResolutionTime(),
|
||||
'by_priority' => $this->getTicketsByPriority(),
|
||||
'by_status' => $this->getTicketsByStatus(),
|
||||
'by_category' => $this->getTicketsByCategory(),
|
||||
'by_assignee' => $this->getTicketsByAssignee()
|
||||
'open_tickets' => (int)($counts['open_tickets'] ?? 0),
|
||||
'closed_tickets' => (int)($counts['closed_tickets'] ?? 0),
|
||||
'created_today' => (int)($counts['created_today'] ?? 0),
|
||||
'created_this_week' => (int)($counts['created_this_week'] ?? 0),
|
||||
'closed_today' => (int)($counts['closed_today'] ?? 0),
|
||||
'unassigned' => (int)($counts['unassigned'] ?? 0),
|
||||
'critical' => (int)($counts['critical'] ?? 0),
|
||||
'avg_resolution_hours' => $counts['avg_resolution'] ? round((float)$counts['avg_resolution'], 1) : 0.0,
|
||||
'by_priority' => $byPriority,
|
||||
'by_status' => $byStatus,
|
||||
'by_category' => $byCategory,
|
||||
'by_assignee' => $byAssignee
|
||||
];
|
||||
}
|
||||
|
||||
|
||||
Reference in New Issue
Block a user