Skip to content

Commit

Permalink
Optimize summary time stats query
Browse files Browse the repository at this point in the history
The query for issues time stats is based on bug history, and history
queries are expensive when scanning a lot of issues.
The previous query retrieves all individual times for each issue, and
then processes all the rows to find the maximum, average, etc. This
processing, for a big number of issues, adds a considerable time to the
function execution.

With this change:
- Introduce a database api check to know if window functions (analytic)
  are supported by current database.
- When window functions are availabe, perform a query that computes the
  aggregated values by itself. The result is now only one row.
- When window functions are not available, perform the simple, non
  aggregated query as before.

The time cost for the windowed query is very similar to the previous
version, but it improves:
- No postprocessing time.
- By returning one row, it can be effectively cached by the database,
  and further reduce times in succesive page loads.
  • Loading branch information
cproensa authored and dregad committed Apr 13, 2019
1 parent 9ba5653 commit 9cd6996
Show file tree
Hide file tree
Showing 3 changed files with 115 additions and 40 deletions.
3 changes: 3 additions & 0 deletions core/constant_inc.php
Expand Up @@ -736,3 +736,6 @@
define( 'DB_TYPE_PGSQL', 2 );
define( 'DB_TYPE_MSSQL', 3 );
define( 'DB_TYPE_ORACLE', 4 );

# Database special capabilities identifiers
define( 'DB_CAPABILITY_WINDOW_FUNCTIONS', 1 );
52 changes: 52 additions & 0 deletions core/database_api.php
Expand Up @@ -1263,3 +1263,55 @@ function db_format_query_log_msg( $p_query, array $p_arr_parms ) {
}
return $p_query;
}

/**
* Returns true if a specific capability is suported in the current database server,
* false otherwise.
*
* @param integer $p_capability See DB_CAPABILITY_* constants
* @return boolean True if the capability is supported, false otherwise.
*/
function db_has_capability( $p_capability ) {
static $s_cache = array();
if( !isset( $s_cache[$p_capability] ) ) {
$s_cache[$p_capability] = db_test_capability( $p_capability );
}
return $s_cache[$p_capability];
}

/**
* Tests if a specific capability is suported in the current database server.
*
* @param integer $p_capability See DB_CAPABILITY_* constants
* @return boolean True if the capability is supported, false otherwise.
*/
function db_test_capability( $p_capability ) {
global $g_db, $g_db_functional_type;
$t_server_info = $g_db->ServerInfo();

switch( $p_capability ) {
case DB_CAPABILITY_WINDOW_FUNCTIONS:
switch( $g_db_functional_type ) {
case DB_TYPE_ORACLE: # since 8i
case DB_TYPE_PGSQL: # since 8.4
case DB_TYPE_MSSQL: # since 2008
return true;
case DB_TYPE_MYSQL:
# mysql, since 8.0.2
if( version_compare( $t_server_info['version'], '8.0.2', '>=' )
&& false !== stripos( $t_server_info['description'], 'mysql' ) ) {
return true;
}
# mariaDB, since 10.2
if( version_compare( $t_server_info['version'], '10.2', '>=' )
&& false !== stripos( $t_server_info['description'], 'mariadb' ) ) {
return true;
}
# if server info cant provide enough information to identify the type,
# default to "not supported"
}
}

# if nothing was found, return false
return false;
}
100 changes: 60 additions & 40 deletions core/summary_api.php
Expand Up @@ -1154,63 +1154,83 @@ function summary_helper_get_time_stats( $p_project_id, array $p_filter = null )
# (e.g. bug is CLOSED, not RESOLVED). The linkage to the history field
# will look up the most recent 'resolved' status change and return it as well

$t_query = new DBQuery();
$t_sql = 'SELECT b.id, b.date_submitted, b.last_updated, MAX(h.date_modified) as hist_update, b.status'
. ' FROM {bug} b LEFT JOIN {bug_history} h'
. ' ON b.id = h.bug_id AND h.type = :hist_type AND h.field_name = :hist_field'
$t_stats = array();

$t_sql_inner = ' FROM {bug} b LEFT JOIN {bug_history} h'
. ' ON b.id = h.bug_id AND h.type = :hist_type'
. ' AND h.field_name = :hist_field AND b.date_submitted <= h.date_modified'
. ' WHERE b.status >= :int_resolved'
. ' AND h.new_value >= :str_resolved AND h.old_value < :str_resolved'
. ' AND ' . $t_specific_where;
$t_query->bind( array(
$t_params = array(
'hist_type' => 0,
'hist_field' => 'status',
'int_resolved' => (int)$t_resolved,
'str_resolved' => (string)$t_resolved
) );
);
if( !empty( $p_filter ) ) {
$t_subquery = filter_cache_subquery( $p_filter );
$t_sql .= ' AND b.id IN :filter';
$t_query->bind( 'filter', $t_subquery );
$t_sql_inner .= ' AND b.id IN :filter';
$t_params['filter'] = $t_subquery;
}
$t_sql .= ' GROUP BY b.id, b.status, b.date_submitted, b.last_updated'
. ' ORDER BY b.id ASC';
$t_query->sql( $t_sql );

$t_bug_count = 0;
$t_largest_diff = 0;
$t_total_time = 0;
while( $t_row = $t_query->fetch() ) {
$t_bug_count++;
$t_date_submitted = $t_row['date_submitted'];
$t_last_updated = $t_row['hist_update'] !== null ? $t_row['hist_update'] : $t_row['last_updated'];
if( db_has_capability( DB_CAPABILITY_WINDOW_FUNCTIONS ) ) {
$t_sql = 'SELECT id, diff, SUM(diff) OVER () AS total_time, AVG(diff) OVER () AS avg_time'
. ' FROM ( SELECT b.id, MAX(h.date_modified) - b.date_submitted AS diff'
. $t_sql_inner
. ' GROUP BY b.id,b.date_submitted ) subquery'
. ' ORDER BY diff DESC';
$t_query = new DbQuery( $t_sql, $t_params );
$t_query->set_limit(1);
if( $t_row = $t_query->fetch() ) {
$t_stats = array(
'bug_id' => $t_row['id'],
'largest_diff' => number_format( (int)$t_row['diff'] / SECONDS_PER_DAY, 2 ),
'total_time' => number_format( (int)$t_row['total_time'] / SECONDS_PER_DAY, 2 ),
'average_time' => number_format( (int)$t_row['avg_time'] / SECONDS_PER_DAY, 2 ),
);
}
} else {
$t_sql = 'SELECT b.id, b.date_submitted, b.last_updated, MAX(h.date_modified) AS hist_update, b.status'
. $t_sql_inner
. ' GROUP BY b.id, b.status, b.date_submitted, b.last_updated ORDER BY b.id ASC';
$t_query = new DbQuery( $t_sql, $t_params );

$t_bug_count = 0;
$t_largest_diff = 0;
$t_total_time = 0;
while( $t_row = $t_query->fetch() ) {
$t_bug_count++;
$t_date_submitted = $t_row['date_submitted'];
$t_last_updated = $t_row['hist_update'] !== null ? $t_row['hist_update'] : $t_row['last_updated'];

if( $t_last_updated < $t_date_submitted ) {
$t_last_updated = 0;
$t_date_submitted = 0;
}

if( $t_last_updated < $t_date_submitted ) {
$t_last_updated = 0;
$t_date_submitted = 0;
$t_diff = $t_last_updated - $t_date_submitted;
$t_total_time += $t_diff;
if( $t_diff > $t_largest_diff ) {
$t_largest_diff = $t_diff;
$t_bug_id = $t_row['id'];
}
}

$t_diff = $t_last_updated - $t_date_submitted;
$t_total_time += $t_diff;
if( $t_diff > $t_largest_diff ) {
$t_largest_diff = $t_diff;
$t_bug_id = $t_row['id'];
if( $t_bug_count > 0 ) {
$t_average_time = $t_total_time / $t_bug_count;
} else {
$t_average_time = 0;
$t_bug_id = 0;
}
}

if( $t_bug_count > 0 ) {
$t_average_time = $t_total_time / $t_bug_count;
} else {
$t_average_time = 0;
$t_bug_id = 0;
$t_stats = array(
'bug_id' => $t_bug_id,
'largest_diff' => number_format( $t_largest_diff / SECONDS_PER_DAY, 2 ),
'total_time' => number_format( $t_total_time / SECONDS_PER_DAY, 2 ),
'average_time' => number_format( $t_average_time / SECONDS_PER_DAY, 2 ),
);
}

$t_stats = array(
'bug_id' => $t_bug_id,
'largest_diff' => number_format( $t_largest_diff / SECONDS_PER_DAY, 2 ),
'total_time' => number_format( $t_total_time / SECONDS_PER_DAY, 2 ),
'average_time' => number_format( $t_average_time / SECONDS_PER_DAY, 2 ),
);

return $t_stats;
}

Expand Down

0 comments on commit 9cd6996

Please sign in to comment.