conn = $conn; } public function getTicketById($id) { $sql = "SELECT t.*, u_created.username as creator_username, u_created.display_name as creator_display_name, u_updated.username as updater_username, u_updated.display_name as updater_display_name, u_assigned.username as assigned_username, u_assigned.display_name as assigned_display_name FROM tickets t LEFT JOIN users u_created ON t.created_by = u_created.user_id LEFT JOIN users u_updated ON t.updated_by = u_updated.user_id LEFT JOIN users u_assigned ON t.assigned_to = u_assigned.user_id WHERE t.ticket_id = ?"; $stmt = $this->conn->prepare($sql); $stmt->bind_param("i", $id); $stmt->execute(); $result = $stmt->get_result(); if ($result->num_rows === 0) { return null; } return $result->fetch_assoc(); } public function getTicketComments($ticketId) { $sql = "SELECT * FROM ticket_comments WHERE ticket_id = ? ORDER BY created_at DESC"; $stmt = $this->conn->prepare($sql); $stmt->bind_param("i", $ticketId); $stmt->execute(); $result = $stmt->get_result(); $comments = []; while ($row = $result->fetch_assoc()) { $comments[] = $row; } return $comments; } public function getAllTickets($page = 1, $limit = 15, $status = 'Open', $sortColumn = 'ticket_id', $sortDirection = 'desc', $category = null, $type = null, $search = null, $filters = []) { // Calculate offset $offset = ($page - 1) * $limit; // Build WHERE clause $whereConditions = []; $params = []; $paramTypes = ''; // Status filtering if ($status) { $statuses = explode(',', $status); $placeholders = str_repeat('?,', count($statuses) - 1) . '?'; $whereConditions[] = "status IN ($placeholders)"; $params = array_merge($params, $statuses); $paramTypes .= str_repeat('s', count($statuses)); } // Category filtering if ($category) { $categories = explode(',', $category); $placeholders = str_repeat('?,', count($categories) - 1) . '?'; $whereConditions[] = "category IN ($placeholders)"; $params = array_merge($params, $categories); $paramTypes .= str_repeat('s', count($categories)); } // Type filtering if ($type) { $types = explode(',', $type); $placeholders = str_repeat('?,', count($types) - 1) . '?'; $whereConditions[] = "type IN ($placeholders)"; $params = array_merge($params, $types); $paramTypes .= str_repeat('s', count($types)); } // Search Functionality if ($search && !empty($search)) { $whereConditions[] = "(title LIKE ? OR description LIKE ? OR ticket_id LIKE ? OR category LIKE ? OR type LIKE ?)"; $searchTerm = "%$search%"; $params = array_merge($params, [$searchTerm, $searchTerm, $searchTerm, $searchTerm, $searchTerm]); $paramTypes .= 'sssss'; } // Advanced search filters // Date range - created_at if (!empty($filters['created_from'])) { $whereConditions[] = "DATE(t.created_at) >= ?"; $params[] = $filters['created_from']; $paramTypes .= 's'; } if (!empty($filters['created_to'])) { $whereConditions[] = "DATE(t.created_at) <= ?"; $params[] = $filters['created_to']; $paramTypes .= 's'; } // Date range - updated_at if (!empty($filters['updated_from'])) { $whereConditions[] = "DATE(t.updated_at) >= ?"; $params[] = $filters['updated_from']; $paramTypes .= 's'; } if (!empty($filters['updated_to'])) { $whereConditions[] = "DATE(t.updated_at) <= ?"; $params[] = $filters['updated_to']; $paramTypes .= 's'; } // Priority range if (!empty($filters['priority_min'])) { $whereConditions[] = "t.priority >= ?"; $params[] = (int)$filters['priority_min']; $paramTypes .= 'i'; } if (!empty($filters['priority_max'])) { $whereConditions[] = "t.priority <= ?"; $params[] = (int)$filters['priority_max']; $paramTypes .= 'i'; } // Created by user if (!empty($filters['created_by'])) { $whereConditions[] = "t.created_by = ?"; $params[] = (int)$filters['created_by']; $paramTypes .= 'i'; } // Assigned to user (including unassigned option) if (!empty($filters['assigned_to'])) { if ($filters['assigned_to'] === 'unassigned') { $whereConditions[] = "t.assigned_to IS NULL"; } else { $whereConditions[] = "t.assigned_to = ?"; $params[] = (int)$filters['assigned_to']; $paramTypes .= 'i'; } } $whereClause = ''; if (!empty($whereConditions)) { $whereClause = 'WHERE ' . implode(' AND ', $whereConditions); } // Validate sort column to prevent SQL injection $allowedColumns = ['ticket_id', 'title', 'status', 'priority', 'category', 'type', 'created_at', 'updated_at', 'created_by', 'assigned_to']; if (!in_array($sortColumn, $allowedColumns)) { $sortColumn = 'ticket_id'; } // Map column names to actual sort expressions // For user columns, sort by display name with NULL handling for unassigned $sortExpression = $sortColumn; if ($sortColumn === 'created_by') { $sortExpression = "COALESCE(u_created.display_name, u_created.username, 'System')"; } elseif ($sortColumn === 'assigned_to') { // Put unassigned (NULL) at the end regardless of sort direction $sortExpression = "CASE WHEN t.assigned_to IS NULL THEN 1 ELSE 0 END, COALESCE(u_assigned.display_name, u_assigned.username)"; } else { $sortExpression = "t.$sortColumn"; } // Validate sort direction $sortDirection = strtolower($sortDirection) === 'asc' ? 'ASC' : 'DESC'; // Get total count for pagination $countSql = "SELECT COUNT(*) as total FROM tickets t $whereClause"; $countStmt = $this->conn->prepare($countSql); if (!empty($params)) { $countStmt->bind_param($paramTypes, ...$params); } $countStmt->execute(); $totalResult = $countStmt->get_result(); $totalTickets = $totalResult->fetch_assoc()['total']; // Get tickets with pagination and creator info $sql = "SELECT t.*, u_created.username as creator_username, u_created.display_name as creator_display_name, u_assigned.username as assigned_username, u_assigned.display_name as assigned_display_name FROM tickets t LEFT JOIN users u_created ON t.created_by = u_created.user_id LEFT JOIN users u_assigned ON t.assigned_to = u_assigned.user_id $whereClause ORDER BY $sortExpression $sortDirection LIMIT ? OFFSET ?"; $stmt = $this->conn->prepare($sql); // Add limit and offset parameters $params[] = $limit; $params[] = $offset; $paramTypes .= 'ii'; if (!empty($params)) { $stmt->bind_param($paramTypes, ...$params); } $stmt->execute(); $result = $stmt->get_result(); $tickets = []; while ($row = $result->fetch_assoc()) { $tickets[] = $row; } return [ 'tickets' => $tickets, 'total' => $totalTickets, 'pages' => ceil($totalTickets / $limit), 'current_page' => $page ]; } public function updateTicket($ticketData, $updatedBy = null) { $sql = "UPDATE tickets SET title = ?, priority = ?, status = ?, description = ?, category = ?, type = ?, updated_by = ?, updated_at = NOW() WHERE ticket_id = ?"; $stmt = $this->conn->prepare($sql); if (!$stmt) { return false; } $stmt->bind_param( "sissssii", $ticketData['title'], $ticketData['priority'], $ticketData['status'], $ticketData['description'], $ticketData['category'], $ticketData['type'], $updatedBy, $ticketData['ticket_id'] ); $result = $stmt->execute(); $stmt->close(); return $result; } public function createTicket($ticketData, $createdBy = null) { // Generate ticket ID (9-digit format with leading zeros) $ticket_id = sprintf('%09d', mt_rand(1, 999999999)); $sql = "INSERT INTO tickets (ticket_id, title, description, status, priority, category, type, created_by, visibility, visibility_groups) VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?)"; $stmt = $this->conn->prepare($sql); // Set default values if not provided $status = $ticketData['status'] ?? 'Open'; $priority = $ticketData['priority'] ?? '4'; $category = $ticketData['category'] ?? 'General'; $type = $ticketData['type'] ?? 'Issue'; $visibility = $ticketData['visibility'] ?? 'public'; $visibilityGroups = $ticketData['visibility_groups'] ?? null; // Validate visibility $allowedVisibilities = ['public', 'internal', 'confidential']; if (!in_array($visibility, $allowedVisibilities)) { $visibility = 'public'; } // Clear visibility_groups if not internal if ($visibility !== 'internal') { $visibilityGroups = null; } $stmt->bind_param( "sssssssiss", $ticket_id, $ticketData['title'], $ticketData['description'], $status, $priority, $category, $type, $createdBy, $visibility, $visibilityGroups ); if ($stmt->execute()) { return [ 'success' => true, 'ticket_id' => $ticket_id ]; } else { return [ 'success' => false, 'error' => $this->conn->error ]; } } public function addComment($ticketId, $commentData) { $sql = "INSERT INTO ticket_comments (ticket_id, user_name, comment_text, markdown_enabled) VALUES (?, ?, ?, ?)"; $stmt = $this->conn->prepare($sql); // Set default username $username = $commentData['user_name'] ?? 'User'; $markdownEnabled = $commentData['markdown_enabled'] ? 1 : 0; $stmt->bind_param( "sssi", $ticketId, $username, $commentData['comment_text'], $markdownEnabled ); if ($stmt->execute()) { return [ 'success' => true, 'user_name' => $username, 'created_at' => date('M d, Y H:i') ]; } else { return [ 'success' => false, 'error' => $this->conn->error ]; } } /** * Assign ticket to a user * * @param int $ticketId Ticket ID * @param int $userId User ID to assign to * @param int $assignedBy User ID performing the assignment * @return bool Success status */ public function assignTicket($ticketId, $userId, $assignedBy) { $sql = "UPDATE tickets SET assigned_to = ?, updated_by = ?, updated_at = NOW() WHERE ticket_id = ?"; $stmt = $this->conn->prepare($sql); $stmt->bind_param("iii", $userId, $assignedBy, $ticketId); $result = $stmt->execute(); $stmt->close(); return $result; } /** * Unassign ticket (set assigned_to to NULL) * * @param int $ticketId Ticket ID * @param int $updatedBy User ID performing the unassignment * @return bool Success status */ public function unassignTicket($ticketId, $updatedBy) { $sql = "UPDATE tickets SET assigned_to = NULL, updated_by = ?, updated_at = NOW() WHERE ticket_id = ?"; $stmt = $this->conn->prepare($sql); $stmt->bind_param("ii", $updatedBy, $ticketId); $result = $stmt->execute(); $stmt->close(); return $result; } /** * Get multiple tickets by IDs in a single query (batch loading) * Eliminates N+1 query problem in bulk operations * * @param array $ticketIds Array of ticket IDs * @return array Associative array keyed by ticket_id */ public function getTicketsByIds($ticketIds) { if (empty($ticketIds)) { return []; } // Sanitize ticket IDs $ticketIds = array_map('intval', $ticketIds); // Create placeholders for IN clause $placeholders = str_repeat('?,', count($ticketIds) - 1) . '?'; $sql = "SELECT t.*, u_created.username as creator_username, u_created.display_name as creator_display_name, u_updated.username as updater_username, u_updated.display_name as updater_display_name, u_assigned.username as assigned_username, u_assigned.display_name as assigned_display_name FROM tickets t LEFT JOIN users u_created ON t.created_by = u_created.user_id LEFT JOIN users u_updated ON t.updated_by = u_updated.user_id LEFT JOIN users u_assigned ON t.assigned_to = u_assigned.user_id WHERE t.ticket_id IN ($placeholders)"; $stmt = $this->conn->prepare($sql); $types = str_repeat('i', count($ticketIds)); $stmt->bind_param($types, ...$ticketIds); $stmt->execute(); $result = $stmt->get_result(); $tickets = []; while ($row = $result->fetch_assoc()) { $tickets[$row['ticket_id']] = $row; } $stmt->close(); return $tickets; } /** * Check if a user can access a ticket based on visibility settings * * @param array $ticket The ticket data * @param array $user The user data (must include user_id, is_admin, groups) * @return bool True if user can access the ticket */ public function canUserAccessTicket($ticket, $user) { // Admins can access all tickets if (!empty($user['is_admin'])) { return true; } $visibility = $ticket['visibility'] ?? 'public'; // Public tickets are accessible to all authenticated users if ($visibility === 'public') { return true; } // Confidential tickets: only creator, assignee, and admins if ($visibility === 'confidential') { $userId = $user['user_id'] ?? null; return ($ticket['created_by'] == $userId || $ticket['assigned_to'] == $userId); } // Internal tickets: check if user is in any of the allowed groups if ($visibility === 'internal') { $allowedGroups = array_filter(array_map('trim', explode(',', $ticket['visibility_groups'] ?? ''))); if (empty($allowedGroups)) { return false; // No groups specified means no access } $userGroups = array_filter(array_map('trim', explode(',', $user['groups'] ?? ''))); // Check if any user group matches any allowed group return !empty(array_intersect($userGroups, $allowedGroups)); } return false; } /** * Build visibility filter SQL for queries * * @param array $user The current user * @return array ['sql' => string, 'params' => array, 'types' => string] */ public function getVisibilityFilter($user) { // Admins see all tickets if (!empty($user['is_admin'])) { return ['sql' => '1=1', 'params' => [], 'types' => '']; } $userId = $user['user_id'] ?? 0; $userGroups = array_filter(array_map('trim', explode(',', $user['groups'] ?? ''))); // Build the visibility filter // 1. Public tickets // 2. Confidential tickets where user is creator or assignee // 3. Internal tickets where user's groups overlap with visibility_groups $conditions = []; $params = []; $types = ''; // Public visibility $conditions[] = "(t.visibility = 'public' OR t.visibility IS NULL)"; // Confidential - user is creator or assignee $conditions[] = "(t.visibility = 'confidential' AND (t.created_by = ? OR t.assigned_to = ?))"; $params[] = $userId; $params[] = $userId; $types .= 'ii'; // Internal - check group membership if (!empty($userGroups)) { $groupConditions = []; foreach ($userGroups as $group) { $groupConditions[] = "FIND_IN_SET(?, REPLACE(t.visibility_groups, ' ', ''))"; $params[] = $group; $types .= 's'; } $conditions[] = "(t.visibility = 'internal' AND (" . implode(' OR ', $groupConditions) . "))"; } return [ 'sql' => '(' . implode(' OR ', $conditions) . ')', 'params' => $params, 'types' => $types ]; } /** * Update ticket visibility settings * * @param int $ticketId * @param string $visibility ('public', 'internal', 'confidential') * @param string|null $visibilityGroups Comma-separated group names for 'internal' visibility * @param int $updatedBy User ID * @return bool */ public function updateVisibility($ticketId, $visibility, $visibilityGroups, $updatedBy) { $allowedVisibilities = ['public', 'internal', 'confidential']; if (!in_array($visibility, $allowedVisibilities)) { $visibility = 'public'; } // Clear visibility_groups if not internal if ($visibility !== 'internal') { $visibilityGroups = null; } $sql = "UPDATE tickets SET visibility = ?, visibility_groups = ?, updated_by = ?, updated_at = NOW() WHERE ticket_id = ?"; $stmt = $this->conn->prepare($sql); $stmt->bind_param("ssii", $visibility, $visibilityGroups, $updatedBy, $ticketId); $result = $stmt->execute(); $stmt->close(); return $result; } }