From 1bc059453365ee6d91b49d888d4b102b7d5c556b Mon Sep 17 00:00:00 2001
From: Jared Hancock <jared@osticket.com>
Date: Thu, 26 Dec 2013 12:38:10 -0600
Subject: [PATCH] perf: Use a materialized view to speed queue views

This patch introduces an automatic materialized view to speed database
performance when querying and displaying the ticket views. This can
eventually be extended to the search and advanced search features to speed
them as well.

The data from the dynamic form entries related to ticket details is copied
to a %ticket__cdata table. The %ticket__cdata table is then joined directly
to the other tables in the query for the ticket view. MySQL is magically
and dramatically faster using this method.

The downside is that the disk usage for the custom data is doubled, and the
time needed to update the dynamic data is at least doubled as the form
entries and the materialized view must both be updated.

This method should also extend well to other database platforms in the
future. It will be likely that most other database query optimizers will
have difficulty joining, scanning, and sorting the table models we have for
custom data fields.
---
 bootstrap.php                   |  2 +-
 include/class.dynamic_forms.php | 97 +++++++++++++++++++++++++++++++++
 include/class.forms.php         | 12 ++++
 include/class.orm.php           | 10 +++-
 include/class.signal.php        |  2 +-
 include/staff/tickets.inc.php   | 51 ++++++++++-------
 6 files changed, 151 insertions(+), 23 deletions(-)

diff --git a/bootstrap.php b/bootstrap.php
index e01920394..ff7cf6b64 100644
--- a/bootstrap.php
+++ b/bootstrap.php
@@ -175,7 +175,7 @@ class Bootstrap {
         require(INCLUDE_DIR.'class.log.php');
         require(INCLUDE_DIR.'class.crypto.php');
         require(INCLUDE_DIR.'class.timezone.php');
-        require(INCLUDE_DIR.'class.signal.php');
+        require_once(INCLUDE_DIR.'class.signal.php');
         require(INCLUDE_DIR.'class.nav.php');
         require(INCLUDE_DIR.'class.page.php');
         require_once(INCLUDE_DIR.'class.format.php'); //format helpers
diff --git a/include/class.dynamic_forms.php b/include/class.dynamic_forms.php
index 52e310935..f48303754 100644
--- a/include/class.dynamic_forms.php
+++ b/include/class.dynamic_forms.php
@@ -18,6 +18,7 @@
 **********************************************************************/
 require_once(INCLUDE_DIR . 'class.orm.php');
 require_once(INCLUDE_DIR . 'class.forms.php');
+require_once(INCLUDE_DIR . 'class.signal.php');
 
 /**
  * Form template, used for designing the custom form and for entering custom
@@ -196,6 +197,85 @@ class TicketForm extends DynamicForm {
         static::$instance = $o[0]->instanciate();
         return static::$instance;
     }
+
+    // Materialized View for Ticket custom data (MySQL FlexViews would be
+    // nice)
+    //
+    // @see http://code.google.com/p/flexviews/
+    static function getDynamicDataViewFields() {
+        $fields = array();
+        foreach (self::getInstance()->getFields() as $f) {
+            $impl = $f->getImpl();
+            if (!$impl->hasData() || $impl->isPresentationOnly())
+                continue;
+
+            $fields[] = sprintf(
+                'MAX(IF(field.name=\'%1$s\',ans.value,NULL)) as `%1$s`',
+                $f->get('name'));
+            if ($impl->hasIdValue()) {
+                $fields[] = sprintf(
+                    'MAX(IF(field.name=\'%1$s\',ans.value_id,NULL)) as `%1$s_id`',
+                    $f->get('name'));
+            }
+        }
+        return $fields;
+    }
+
+    static function ensureDynamicDataView() {
+        $sql = 'SHOW TABLES LIKE \''.TABLE_PREFIX.'ticket__cdata\'';
+        if (!db_num_rows(db_query($sql)))
+            return static::buildDynamicDataView();
+    }
+
+    static function buildDynamicDataView() {
+        // create  table __cdata (primary key (ticket_id)) as select
+        // entry.object_id as ticket_id, MAX(IF(field.name = 'subject',
+        // ans.value, NULL)) as `subject`,MAX(IF(field.name = 'priority',
+        // ans.value, NULL)) as `priority_desc`,MAX(IF(field.name =
+        // 'priority', ans.value_id, NULL)) as `priority_id`
+        // FROM ost_form_entry entry LEFT JOIN ost_form_entry_values ans ON
+        // ans.entry_id = entry.id LEFT JOIN ost_form_field field ON
+        // field.id=ans.field_id
+        // where entry.object_type='T' group by entry.object_id;
+        $fields = static::getDynamicDataViewFields();
+        $sql = 'CREATE TABLE `'.TABLE_PREFIX.'ticket__cdata` (PRIMARY KEY (ticket_id)) AS
+            SELECT entry.`object_id` AS ticket_id, '.implode(',', $fields)
+         .' FROM ost_form_entry entry
+            JOIN ost_form_entry_values ans ON ans.entry_id = entry.id
+            JOIN ost_form_field field ON field.id=ans.field_id
+            WHERE entry.object_type=\'T\' GROUP BY entry.object_id';
+        db_query($sql);
+    }
+
+    static function dropDynamicDataView() {
+        db_query('DROP TABLE IF EXISTS `'.TABLE_PREFIX.'ticket__cdata`');
+    }
+
+    static function updateDynamicDataView($answer, $data) {
+        // TODO: Detect $data['dirty'] for value and value_id
+        // We're chiefly concerned with Ticket form answers
+        if (!($e = $answer->getEntry()) || $e->get('object_type') != 'T')
+            return;
+
+        // If the `name` column is in the dirty list, we would be renaming a
+        // column. Delete the view instead.
+        if (isset($data['dirty']) && isset($data['dirty']['name']))
+            return self::dropDynamicDataView();
+
+        // $record = array();
+        // $record[$f] = $answer->value'
+        // TicketFormData::objects()->filter(array('ticket_id'=>$a))
+        //      ->merge($record);
+        $f = $answer->getField()->get('name');
+        $ids = $answer->getField()->hasIdValue();
+        $fields = sprintf('`%s`=', $f) . db_input($answer->get('value'));
+        if ($answer->getField()->hasIdValue())
+            $fields .= sprintf(',`%s_id`=', $f) . db_input($answer->getIdValue());
+        $sql = 'INSERT INTO `'.TABLE_PREFIX.'ticket__cdata` SET '.$fields
+            .', `ticket_id`='.db_input($answer->getEntry()->get('object_id'))
+            .' ON DUPLICATE KEY UPDATE '.$fields;
+        db_query($sql);
+    }
 }
 // Add fields from the standard ticket form to the ticket filterable fields
 Filter::addSupportedMatches('Custom Fields', function() {
@@ -207,6 +287,22 @@ Filter::addSupportedMatches('Custom Fields', function() {
     }
     return $matches;
 });
+Signal::connect('model.created',
+    array('TicketForm', 'updateDynamicDataView'),
+    'DynamicFormEntryAnswer');
+Signal::connect('model.updated',
+    array('TicketForm', 'updateDynamicDataView'),
+    'DynamicFormEntryAnswer');
+// Recreate the dynamic view after new or removed fields to the ticket
+// details form
+Signal::connect('model.created',
+    array('TicketForm', 'dropDynamicDataView'),
+    'DynamicFormField',
+    function($o) { return $o->getForm()->get('type') == 'T'; });
+Signal::connect('model.deleted',
+    array('TicketForm', 'dropDynamicDataView'),
+    'DynamicFormField',
+    function($o) { return $o->getForm()->get('type') == 'T'; });
 
 require_once(INCLUDE_DIR . "class.json.php");
 
@@ -555,6 +651,7 @@ class DynamicFormEntry extends VerySimpleModel {
                 array('field_id'=>$f->get('id')));
             $a->field = $f;
             $a->field->setAnswer($a);
+            $a->entry = $inst;
             $inst->_values[] = $a;
         }
         return $inst;
diff --git a/include/class.forms.php b/include/class.forms.php
index bff57fc4c..a09f25cdb 100644
--- a/include/class.forms.php
+++ b/include/class.forms.php
@@ -434,6 +434,14 @@ class FormField {
         return $this->presentation_only;
     }
 
+    /**
+     * Indicates if the field places data in the `value_id` column. This
+     * is currently used by the materialized view system
+     */
+    function hasIdValue() {
+        return false;
+    }
+
     function getConfigurationForm() {
         if (!$this->_cform) {
             $type = static::getFieldType($this->get('type'));
@@ -787,6 +795,10 @@ class PriorityField extends ChoiceField {
         return $widget;
     }
 
+    function hasIdValue() {
+        return true;
+    }
+
     function getChoices() {
         $this->ht['default'] = 0;
 
diff --git a/include/class.orm.php b/include/class.orm.php
index 38d3482da..dee287cea 100644
--- a/include/class.orm.php
+++ b/include/class.orm.php
@@ -147,7 +147,10 @@ class VerySimpleModel {
         foreach ($pk as $p)
             $filter[] = $p.' = '.db_input($this->get($p));
         $sql .= ' WHERE '.implode(' AND ', $filter).' LIMIT 1';
-        return db_query($sql) && db_affected_rows() == 1;
+        if (!db_query($sql) || db_affected_rows() != 1)
+            throw new Exception(db_error());
+        Signal::send('model.deleted', $this);
+        return true;
     }
 
     function save($refetch=false) {
@@ -183,6 +186,11 @@ class VerySimpleModel {
             $this->__new__ = false;
             // Setup lists again
             $this->__setupForeignLists();
+            Signal::send('model.created', $this);
+        }
+        else {
+            $data = array('dirty' => $this->dirty);
+            Signal::send('model.updated', $this, $data);
         }
         # Refetch row from database
         # XXX: Too much voodoo
diff --git a/include/class.signal.php b/include/class.signal.php
index f931acebc..928c15c4d 100644
--- a/include/class.signal.php
+++ b/include/class.signal.php
@@ -93,7 +93,7 @@ class Signal {
             list($s, $callable, $check) = $sub;
             if ($s && !is_a($object, $s))
                 continue;
-            elseif ($check && !call_user_func($check, $data))
+            elseif ($check && !call_user_func($check, $object, $data))
                 continue;
             call_user_func($callable, $object, $data);
         }
diff --git a/include/staff/tickets.inc.php b/include/staff/tickets.inc.php
index e463e515d..205956a91 100644
--- a/include/staff/tickets.inc.php
+++ b/include/staff/tickets.inc.php
@@ -192,10 +192,7 @@ $$x=' class="'.strtolower($order).'" ';
 if($_GET['limit'])
     $qstr.='&limit='.urlencode($_GET['limit']);
 
-$qselect ='SELECT DISTINCT ticket.ticket_id,lock_id,ticketID,ticket.dept_id,ticket.staff_id,ticket.team_id '
-    .',MAX(IF(field.name = \'subject\', ans.value, NULL)) as `subject`'
-    .',MAX(IF(field.name = \'priority\', ans.value, NULL)) as `priority_desc`'
-    .',MAX(IF(field.name = \'priority\', ans.value_id, NULL)) as `priority_id`'
+$qselect ='SELECT ticket.ticket_id,lock_id,ticketID,ticket.dept_id,ticket.staff_id,ticket.team_id '
     .' ,user.name'
     .' ,email.address as email, dept_name '
          .' ,ticket.status,ticket.source,isoverdue,isanswered,ticket.created ';
@@ -203,18 +200,13 @@ $qselect ='SELECT DISTINCT ticket.ticket_id,lock_id,ticketID,ticket.dept_id,tick
 $qfrom=' FROM '.TICKET_TABLE.' ticket '.
        ' LEFT JOIN '.USER_TABLE.' user ON user.id = ticket.user_id'.
        ' LEFT JOIN '.USER_EMAIL_TABLE.' email ON user.id = email.user_id'.
-       ' LEFT JOIN '.DEPT_TABLE.' dept ON ticket.dept_id=dept.dept_id '.
-       ' LEFT JOIN '.FORM_ENTRY_TABLE.' entry ON entry.object_type=\'T\'
-             and entry.object_id=ticket.ticket_id'.
-       ' LEFT JOIN '.FORM_ANSWER_TABLE.' ans ON ans.entry_id = entry.id'.
-       ' LEFT JOIN '.FORM_FIELD_TABLE.' field ON field.id=ans.field_id';
+       ' LEFT JOIN '.DEPT_TABLE.' dept ON ticket.dept_id=dept.dept_id ';
 
 $sjoin='';
 if($search && $deep_search) {
     $sjoin=' LEFT JOIN '.TICKET_THREAD_TABLE.' thread ON (ticket.ticket_id=thread.ticket_id )';
 }
 
-$qgroup=' GROUP BY ticket.ticket_id';
 //get ticket count based on the query so far..
 $total=db_count("SELECT count(DISTINCT ticket.ticket_id) $qfrom $sjoin $qwhere");
 //pagenate
@@ -224,23 +216,23 @@ $pageNav=new Pagenate($total,$page,$pagelimit);
 $pageNav->setURL('tickets.php',$qstr.'&sort='.urlencode($_REQUEST['sort']).'&order='.urlencode($_REQUEST['order']));
 
 //ADD attachment,priorities, lock and other crap
-$qselect.=' ,count(attach.attach_id) as attachments '
-         .' ,count(DISTINCT thread.id) as thread_count '
-         .' ,IF(ticket.duedate IS NULL,IF(sla.id IS NULL, NULL, DATE_ADD(ticket.created, INTERVAL sla.grace_period HOUR)), ticket.duedate) as duedate '
+$qselect.=' ,IF(ticket.duedate IS NULL,IF(sla.id IS NULL, NULL, DATE_ADD(ticket.created, INTERVAL sla.grace_period HOUR)), ticket.duedate) as duedate '
          .' ,CAST(GREATEST(IFNULL(ticket.lastmessage, 0), IFNULL(ticket.reopened, 0), ticket.created) as datetime) as effective_date '
          .' ,CONCAT_WS(" ", staff.firstname, staff.lastname) as staff, team.name as team '
          .' ,IF(staff.staff_id IS NULL,team.name,CONCAT_WS(" ", staff.lastname, staff.firstname)) as assigned '
-         .' ,IF(ptopic.topic_pid IS NULL, topic.topic, CONCAT_WS(" / ", ptopic.topic, topic.topic)) as helptopic ';
+         .' ,IF(ptopic.topic_pid IS NULL, topic.topic, CONCAT_WS(" / ", ptopic.topic, topic.topic)) as helptopic '
+         .' ,cdata.priority_id, cdata.subject';
 
 $qfrom.=' LEFT JOIN '.TICKET_LOCK_TABLE.' tlock ON (ticket.ticket_id=tlock.ticket_id AND tlock.expire>NOW()
                AND tlock.staff_id!='.db_input($thisstaff->getId()).') '
-       .' 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) '
        .' LEFT JOIN '.STAFF_TABLE.' staff ON (ticket.staff_id=staff.staff_id) '
        .' LEFT JOIN '.TEAM_TABLE.' team ON (ticket.team_id=team.team_id) '
        .' LEFT JOIN '.SLA_TABLE.' sla ON (ticket.sla_id=sla.id AND sla.isactive=1) '
        .' LEFT JOIN '.TOPIC_TABLE.' topic ON (ticket.topic_id=topic.topic_id) '
-       .' LEFT JOIN '.TOPIC_TABLE.' ptopic ON (ptopic.topic_id=topic.topic_pid) ';
+       .' LEFT JOIN '.TOPIC_TABLE.' ptopic ON (ptopic.topic_id=topic.topic_pid) '
+       .' LEFT JOIN '.TABLE_PREFIX.'ticket__cdata cdata ON (cdata.ticket_id = ticket.ticket_id) ';
+
+TicketForm::ensureDynamicDataView();
 
 // Fetch priority information
 $res = db_query('select * from '.PRIORITY_TABLE);
@@ -248,7 +240,7 @@ $prios = array();
 while ($row = db_fetch_array($res))
     $prios[$row['priority_id']] = $row;
 
-$query="$qselect $qfrom $qwhere $qgroup ORDER BY $order_by $order LIMIT ".$pageNav->getStart().",".$pageNav->getLimit();
+$query="$qselect $qfrom $qwhere ORDER BY $order_by $order LIMIT ".$pageNav->getStart().",".$pageNav->getLimit();
 //echo $query;
 $hash = md5($query);
 $_SESSION['search_'.$hash] = $query;
@@ -262,6 +254,25 @@ if($search)
 
 $negorder=$order=='DESC'?'ASC':'DESC'; //Negate the sorting..
 
+// Fetch the results
+$results = array();
+while ($row = db_fetch_array($res)) {
+    $results[$row['ticket_id']] = $row;
+}
+
+// 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;
+}
+
 //YOU BREAK IT YOU FIX IT.
 ?>
 <!-- SEARCH FORM START -->
@@ -345,9 +356,9 @@ $negorder=$order=='DESC'?'ASC':'DESC'; //Negate the sorting..
         <?php
         $class = "row1";
         $total=0;
-        if($res && ($num=db_num_rows($res))):
+        if($res && ($num=count($results))):
             $ids=($errors && $_POST['tids'] && is_array($_POST['tids']))?$_POST['tids']:null;
-            while ($row = db_fetch_array($res)) {
+            foreach ($results as $row) {
                 $tag=$row['staff_id']?'assigned':'openticket';
                 $flag=null;
                 if($row['lock_id'])
-- 
GitLab