Procházet zdrojové kódy

Issue #2463211: Updated the cvterm views handler to use loose index scan to generate the drop-down list

Nathan Weeks před 9 roky
rodič
revize
2c224cc6da

+ 79 - 30
tripal_views/views/handlers/tripal_views_handler_filter_select_cvterm.inc

@@ -23,10 +23,65 @@ class tripal_views_handler_filter_select_cvterm extends tripal_views_handler_fil
    */
   function get_select_options() {
 
-    if (isset($this->options['show_all'])) {
-      $cv_id = variable_get('chado_' . $this->view->base_table . '_cv', NULL);
-      if ($cv_id) {
-        $results = chado_select_record('cvterm', array('cvterm_id', 'name'), array('cv_id' => $cv_id));
+    // If the admin has set the "Show All" option then we want to show all the
+    // cvterms regardless of whether they are used in the base table or not.
+    if (isset($this->options['show_all']) AND $this->options['show_all'] == TRUE) {
+
+      // Get a list of cvs currently used.
+
+      // If the filter is for a field in the cvterm table (weird, I know but
+      // we can't assume that tripal admin won't do this) then we only need
+      // to make one-hop to the cv table.
+      if ($this->table == 'cvterm') {
+        // Using a "Loose Index Scan" to get a list of all the cvs used
+        // in the cvterm table (ie: all the cv's with at least one term).
+        // See https://wiki.postgresql.org/wiki/Loose_indexscan
+        $sql = "
+          WITH RECURSIVE t AS (
+            SELECT MIN(cv_id) AS col FROM {!table}
+            UNION ALL
+            SELECT (SELECT MIN(cv_id) FROM {!table} WHERE cv_id > col)
+            FROM t WHERE col IS NOT NULL
+          )
+          SELECT cv_id, name
+            FROM {cv}
+            WHERE cv_id IN (SELECT col FROM t where col IS NOT NULL)
+            ORDER BY cv.name ASC";
+        $sql = format_string($sql, array('!table' => $this->table));
+      }
+      // Otherwise, (most often the case) we need to make two-hops
+      // to the cv table through the cvterm table.
+      else {
+        // Using a "Loose Index Scan" to get a list of all the cvs used
+        // in the table the drop-down filter is from.
+        // See https://wiki.postgresql.org/wiki/Loose_indexscan
+        $sql = "
+          WITH RECURSIVE t AS (
+            SELECT MIN(cvterm.cv_id) AS col
+              FROM {!table} filter_table
+              LEFT JOIN {cvterm} ON filter_table.!field=cvterm.cvterm_id
+            UNION ALL
+            SELECT (
+                SELECT MIN(cv_id)
+                FROM {!table} filter_table
+                LEFT JOIN {cvterm} ON filter_table.!field=cvterm.cvterm_id
+                WHERE cv_id > col
+              )
+              FROM t WHERE col IS NOT NULL
+          )
+          SELECT cv_id, name
+            FROM chado.cv
+            WHERE cv_id IN (SELECT col FROM t where col IS NOT NULL)
+            ORDER BY cv.name ASC";
+        $sql = format_string($sql, array('!table' => $this->table, '!field' => $this->field));
+      }
+      $resource = chado_query($sql);
+
+      // Now actually gerenate the select list
+      // based on the results from the above query.
+      $cvterms = array();
+      foreach ($resource as $r) {
+        $results = chado_select_record('cvterm', array('cvterm_id', 'name'), array('cv_id' => $r->cv_id));
         if (empty($results)) {
           $results = array();
         }
@@ -34,31 +89,10 @@ class tripal_views_handler_filter_select_cvterm extends tripal_views_handler_fil
           $cvterms[$c->cvterm_id] = $c->name;
         }
       }
-      else {
-        //get a list of cvs currently used
-        if ($this->view->base_table == 'cvterm') {
-          $sql = 'SELECT distinct(cv.cv_id) FROM chado.' . $this->view->base_table
-            .' LEFT JOIN chado.cv cv ON cv.cv_id=cvterm.cv_id';
-        }
-        else {
-          $sql = 'SELECT distinct(cv.cv_id) FROM chado.' . $this->view->base_table
-            .' LEFT JOIN chado.cvterm cvterm ON cvterm.cvterm_id=' . $this->view->base_table . '.type_id '
-            .'LEFT JOIN chado.cv cv ON cv.cv_id=cvterm.cv_id';
-        }
-        $resource = chado_query($sql);
-        $cvterms = array();
-        foreach ($resource as $r) {
-          $results = chado_select_record('cvterm', array('cvterm_id', 'name'), array('cv_id' => $r->cv_id));
-          if (empty($results)) {
-            $results = array();
-          }
-          foreach ($results as $c) {
-            $cvterms[$c->cvterm_id] = $c->name;
-          }
-        }
-      }// end of if variable not defined
 
     }
+    // Otherwise, show the user the much smaller list of all cvterms used in
+    // the base table.
     else {
 
       $where_clauses = $this->get_select_option_where();
@@ -67,20 +101,35 @@ class tripal_views_handler_filter_select_cvterm extends tripal_views_handler_fil
         $where = ' AND ' . implode(' AND ', $where_clauses);
       }
 
-      $sql = "SELECT cvterm_id, name FROM {cvterm} WHERE cvterm_id IN (SELECT distinct(" . $this->field . ") FROM {" . $this->table . "}) " . $where . ' ORDER BY cvterm.name ASC';
+      // Using a "Loose Index Scan" to get a list of all the cvterms used
+      // in the base table. See https://wiki.postgresql.org/wiki/Loose_indexscan
+      $sql = "
+        WITH RECURSIVE t AS (
+          SELECT MIN(!field) AS col FROM {!table} " . ($where == '' ? '' : "WHERE " . $where) . "
+          UNION ALL
+          SELECT (SELECT MIN(!field) FROM {!table} WHERE !field > col " . $where . ")
+          FROM t WHERE col IS NOT NULL
+        )
+        SELECT cvterm_id, name
+          FROM {cvterm}
+          WHERE cvterm_id IN (SELECT col FROM t where col IS NOT NULL)
+          ORDER BY cvterm.name ASC";
+      $sql = format_string($sql, array('!table' => $this->table, '!field' => $this->field));
+
       $resource = chado_query($sql);
       $cvterms = array();
 
+      // Add an "- Any - " option to allow a type to not be set by default.
       if ($this->options['select_optional']) {
         $cvterms['All'] = '- Any -';
       }
 
+      // Now actually gerenate the select list
+      // based on the results from the above query.
       foreach ($resource as $r) {
         $cvterms[$r->cvterm_id] = $r->name;
       }
     }
-    //sort cvterms by name (case insensitive)
-    natcasesort($cvterms);
 
     return $cvterms;