From 4d281128ccc1332ca74e3343d253282bf5c9b71e Mon Sep 17 00:00:00 2001 From: Jared Hancock <jared@osticket.com> Date: Thu, 2 Jan 2014 15:57:17 -0600 Subject: [PATCH] Improve advanced search performance Use a union query to avoid using DISTINCT and lots and lots of joins in the from clause. Initial tests seem to indicate about a 80% faster (~500ms down from ~800ms) on querying about 9k tickets). --- include/ajax.tickets.php | 51 ++++++++++++++++++++--------------- include/staff/tickets.inc.php | 25 ++++++++++------- 2 files changed, 44 insertions(+), 32 deletions(-) diff --git a/include/ajax.tickets.php b/include/ajax.tickets.php index b8e98b8c8..c44f8dbf2 100644 --- a/include/ajax.tickets.php +++ b/include/ajax.tickets.php @@ -103,12 +103,10 @@ class TicketsAjaxAPI extends AjaxController { global $thisstaff, $cfg; $result=array(); - $select = 'SELECT DISTINCT ticket.ticket_id'; + $select = 'SELECT ticket.ticket_id'; $from = ' FROM '.TICKET_TABLE.' ticket '; - $where = ' WHERE 1 '; - //Access control. - $where.=' AND ( ticket.staff_id='.db_input($thisstaff->getId()); + $where = ' WHERE ( ticket.staff_id='.db_input($thisstaff->getId()); if(($teams=$thisstaff->getTeams()) && count(array_filter($teams))) $where.=' OR ticket.team_id IN('.implode(',', db_input(array_filter($teams))).')'; @@ -179,28 +177,33 @@ class TicketsAjaxAPI extends AjaxController { $where.=' AND ticket.created<=FROM_UNIXTIME('.$endTime.')'; //Query + $joins = array(); if($req['query']) { $queryterm=db_real_escape($req['query'], false); - $from.=' LEFT JOIN '.TICKET_THREAD_TABLE.' thread ON (ticket.ticket_id=thread.ticket_id )' - .' LEFT JOIN '.FORM_ENTRY_TABLE.' tentry ON (tentry.object_id = ticket.ticket_id - AND tentry.object_type="T") - LEFT JOIN '.FORM_ANSWER_TABLE.' tans ON (tans.entry_id = tentry.id - AND tans.value_id IS NULL) - LEFT JOIN '.FORM_ENTRY_TABLE.' uentry ON (uentry.object_id = ticket.user_id + // Setup sets of joins and queries + $joins[] = array( + 'from' => + 'LEFT JOIN '.TICKET_THREAD_TABLE.' thread ON (ticket.ticket_id=thread.ticket_id )', + 'where' => "thread.title LIKE '%$queryterm%' OR thread.body LIKE '%$queryterm%'" + ); + $joins[] = array( + 'from' => + 'LEFT JOIN '.FORM_ENTRY_TABLE.' tentry ON (tentry.object_id = ticket.ticket_id AND tentry.object_type="T") + LEFT JOIN '.FORM_ANSWER_TABLE.' tans ON (tans.entry_id = tentry.id AND tans.value_id IS NULL)', + 'where' => "tans.value LIKE '%$queryterm%'" + ); + $joins[] = array( + 'from' => + 'LEFT JOIN '.FORM_ENTRY_TABLE.' uentry ON (uentry.object_id = ticket.user_id AND uentry.object_type="U") LEFT JOIN '.FORM_ANSWER_TABLE.' uans ON (uans.entry_id = uentry.id AND uans.value_id IS NULL) LEFT JOIN '.USER_TABLE.' user ON (ticket.user_id = user.id) - LEFT JOIN '.USER_EMAIL_TABLE.' uemail ON (user.id = uemail.user_id)'; - - $where.=" AND ( uemail.address LIKE '%$queryterm%'" - ." OR user.name LIKE '%$queryterm%'" - ." OR tans.value LIKE '%$queryterm%'" - ." OR uans.value LIKE '%$queryterm%'" - ." OR thread.title LIKE '%$queryterm%'" - ." OR thread.body LIKE '%$queryterm%'" - .' )'; + LEFT JOIN '.USER_EMAIL_TABLE.' uemail ON (user.id = uemail.user_id)', + 'where' => + "uemail.address LIKE '%$queryterm%' OR user.name LIKE '%$queryterm%' OR uans.value LIKE '%$queryterm%'", + ); } // Dynamic fields @@ -224,12 +227,16 @@ class TicketsAjaxAPI extends AjaxController { $from .= ' LEFT JOIN '.sprintf($dynfields, implode(',', $vals)) ." dyn ON (dyn.object_id = ticket.ticket_id)"; - $sql="$select $from $where"; + $sections = array(); + foreach ($joins as $j) { + $sections[] = "$select $from {$j['from']} $where AND ({$j['where']})"; + } + $sql=implode(' union ', $sections); $res = db_query($sql); $tickets = array(); - while (list($tickets[]) = db_fetch_row($res)); - $tickets = array_filter($tickets); + while ($row = db_fetch_row($res)) + $tickets[] = $row[0]; return $tickets; } diff --git a/include/staff/tickets.inc.php b/include/staff/tickets.inc.php index 205956a91..1415ce76d 100644 --- a/include/staff/tickets.inc.php +++ b/include/staff/tickets.inc.php @@ -129,6 +129,9 @@ if($search): if (count($tickets)) $qwhere .= ' AND ticket.ticket_id IN ('. implode(',',db_input($tickets)).')'; + else + // No hits -- there should be an empty list of results + $qwhere .= ' AND false'; } } @@ -261,16 +264,18 @@ while ($row = db_fetch_array($res)) { } // Fetch attachment and thread entry counts -$counts_sql = 'SELECT ticket.ticket_id, count(attach.attach_id) as attachments, - count(DISTINCT thread.id) as thread_count - FROM '.TICKET_TABLE.' ticket - LEFT JOIN '.TICKET_ATTACHMENT_TABLE.' attach ON (ticket.ticket_id=attach.ticket_id) ' - .' LEFT JOIN '.TICKET_THREAD_TABLE.' thread ON ( ticket.ticket_id=thread.ticket_id) ' - .' WHERE ticket.ticket_id IN ('.implode(',', db_input(array_keys($results))).') - GROUP BY ticket.ticket_id'; -$ids_res = db_query($counts_sql); -while ($row = db_fetch_array($ids_res)) { - $results[$row['ticket_id']] += $row; +if ($results) { + $counts_sql = 'SELECT ticket.ticket_id, count(attach.attach_id) as attachments, + count(DISTINCT thread.id) as thread_count + FROM '.TICKET_TABLE.' ticket + LEFT JOIN '.TICKET_ATTACHMENT_TABLE.' attach ON (ticket.ticket_id=attach.ticket_id) ' + .' LEFT JOIN '.TICKET_THREAD_TABLE.' thread ON ( ticket.ticket_id=thread.ticket_id) ' + .' WHERE ticket.ticket_id IN ('.implode(',', db_input(array_keys($results))).') + GROUP BY ticket.ticket_id'; + $ids_res = db_query($counts_sql); + while ($row = db_fetch_array($ids_res)) { + $results[$row['ticket_id']] += $row; + } } //YOU BREAK IT YOU FIX IT. -- GitLab