conn = $conn; } /** * Get count of open tickets */ public function getOpenTicketCount(): int { $sql = "SELECT COUNT(*) as count FROM tickets WHERE status IN ('Open', 'Pending', 'In Progress')"; $result = $this->conn->query($sql); $row = $result->fetch_assoc(); return (int)$row['count']; } /** * Get count of closed tickets */ public function getClosedTicketCount(): int { $sql = "SELECT COUNT(*) as count FROM tickets WHERE status = 'Closed'"; $result = $this->conn->query($sql); $row = $result->fetch_assoc(); return (int)$row['count']; } /** * Get tickets grouped by priority */ public function getTicketsByPriority(): array { $sql = "SELECT priority, COUNT(*) as count FROM tickets WHERE status != 'Closed' GROUP BY priority ORDER BY priority"; $result = $this->conn->query($sql); $data = []; while ($row = $result->fetch_assoc()) { $data['P' . $row['priority']] = (int)$row['count']; } return $data; } /** * Get tickets grouped by status */ public function getTicketsByStatus(): array { $sql = "SELECT status, COUNT(*) as count FROM tickets GROUP BY status ORDER BY FIELD(status, 'Open', 'Pending', 'In Progress', 'Closed')"; $result = $this->conn->query($sql); $data = []; while ($row = $result->fetch_assoc()) { $data[$row['status']] = (int)$row['count']; } return $data; } /** * Get tickets grouped by category */ public function getTicketsByCategory(): array { $sql = "SELECT category, COUNT(*) as count FROM tickets WHERE status != 'Closed' GROUP BY category ORDER BY count DESC"; $result = $this->conn->query($sql); $data = []; while ($row = $result->fetch_assoc()) { $data[$row['category']] = (int)$row['count']; } return $data; } /** * Get average resolution time in hours */ public function getAverageResolutionTime(): float { $sql = "SELECT AVG(TIMESTAMPDIFF(HOUR, created_at, updated_at)) as avg_hours FROM tickets WHERE status = 'Closed' AND created_at IS NOT NULL AND updated_at IS NOT NULL AND updated_at > created_at"; $result = $this->conn->query($sql); $row = $result->fetch_assoc(); return $row['avg_hours'] ? round($row['avg_hours'], 1) : 0; } /** * Get count of tickets created today */ public function getTicketsCreatedToday(): int { $sql = "SELECT COUNT(*) as count FROM tickets WHERE DATE(created_at) = CURDATE()"; $result = $this->conn->query($sql); $row = $result->fetch_assoc(); return (int)$row['count']; } /** * Get count of tickets created this week */ public function getTicketsCreatedThisWeek(): int { $sql = "SELECT COUNT(*) as count FROM tickets WHERE YEARWEEK(created_at, 1) = YEARWEEK(CURDATE(), 1)"; $result = $this->conn->query($sql); $row = $result->fetch_assoc(); return (int)$row['count']; } /** * Get count of tickets closed today */ public function getTicketsClosedToday(): int { $sql = "SELECT COUNT(*) as count FROM tickets WHERE status = 'Closed' AND DATE(updated_at) = CURDATE()"; $result = $this->conn->query($sql); $row = $result->fetch_assoc(); return (int)$row['count']; } /** * Get tickets by assignee (top 5) */ public function getTicketsByAssignee(int $limit = 5): array { $sql = "SELECT u.display_name, u.username, COUNT(t.ticket_id) as ticket_count FROM tickets t JOIN users u ON t.assigned_to = u.user_id WHERE t.status != 'Closed' GROUP BY t.assigned_to ORDER BY ticket_count DESC LIMIT ?"; $stmt = $this->conn->prepare($sql); $stmt->bind_param('i', $limit); $stmt->execute(); $result = $stmt->get_result(); $data = []; while ($row = $result->fetch_assoc()) { $name = $row['display_name'] ?: $row['username']; $data[$name] = (int)$row['ticket_count']; } $stmt->close(); return $data; } /** * Get unassigned ticket count */ public function getUnassignedTicketCount(): int { $sql = "SELECT COUNT(*) as count FROM tickets WHERE assigned_to IS NULL AND status != 'Closed'"; $result = $this->conn->query($sql); $row = $result->fetch_assoc(); return (int)$row['count']; } /** * Get critical (P1) ticket count */ public function getCriticalTicketCount(): int { $sql = "SELECT COUNT(*) as count FROM tickets WHERE priority = 1 AND status != 'Closed'"; $result = $this->conn->query($sql); $row = $result->fetch_assoc(); return (int)$row['count']; } /** * Get all stats as a single array * * Uses caching to reduce database load. Stats are cached for STATS_CACHE_TTL seconds. * * @param bool $forceRefresh Force a cache refresh * @return array All dashboard statistics */ public function getAllStats(bool $forceRefresh = false): array { $cacheKey = 'dashboard_all'; if ($forceRefresh) { CacheHelper::delete(self::CACHE_PREFIX, $cacheKey); } return CacheHelper::remember( self::CACHE_PREFIX, $cacheKey, function() { return $this->fetchAllStats(); }, self::STATS_CACHE_TTL ); } /** * 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' => (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 ]; } /** * Invalidate cached stats * * Call this method when ticket data changes to ensure fresh stats. */ public function invalidateCache(): void { CacheHelper::delete(self::CACHE_PREFIX, null); } }