Skip to content

Commit

Permalink
Improve performance of Summary Page queries
Browse files Browse the repository at this point in the history
Fixes #25693
PR #1479
  • Loading branch information
dregad committed Apr 14, 2019
2 parents 9ba5653 + 0abb605 commit 89eef28
Show file tree
Hide file tree
Showing 3 changed files with 162 additions and 141 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;
}
248 changes: 107 additions & 141 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 Expand Up @@ -1275,144 +1295,89 @@ function summary_print_filter_info( array $p_filter = null ) {
}

/**
* Calculate the number of "resolve" issues actions in the last X days.
* This includes each and succesive resolution transitions.
* Calculate the number of "open" and "resolve" issues actions in the last X days.
* This includes each and successive resolution transitions.
* A filter can be used to limit the visibility.
*
* @param array $p_date_array An array of integers representing days is passed in.
* @param array $p_filter Filter array.
* @return array Accumulated count for each day range
* @param array $p_date_array An array of integers representing days is passed in.
* @param array $p_filter Filter array.
* @return array Accumulated count for each day range.
*/
function summary_by_dates_resolved_bug_count( array $p_date_array, array $p_filter = null ) {
function summary_by_dates_bug_count( array $p_date_array, array $p_filter = null ) {
$t_project_id = helper_get_current_project();
$t_specific_where = helper_project_specific_where( $t_project_id );
$t_resolved = config_get( 'bug_resolved_status_threshold' );

$t_date_array = array_values( $p_date_array );
sort( $t_date_array );
$t_query = new DBQuery();

$t_prev_days = 0;
$t_query = new DBQuery();
$t_now = db_now();
$t_prev_days = 0;
$t_sql_ranges = 'CASE';
foreach( $t_date_array as $t_ix => $t_days ) {
$c_days = (int)$t_days;
$t_range_start = $t_now - $c_days * SECONDS_PER_DAY + 1;
$t_range_end = $t_now - $t_prev_days * SECONDS_PER_DAY;
$t_sql_ranges .= ' WHEN h.date_modified'
$t_sql_ranges .= ' WHEN date_modified'
. ' BETWEEN ' . $t_query->param( $t_range_start )
. ' AND ' . $t_query->param( $t_range_end )
. ' THEN ' . $t_ix;
$t_prev_days = $c_days;
}
$t_sql_ranges .= ' ELSE -1 END';

$t_sql = 'SELECT date_range, COUNT( id ) AS range_count FROM ('
. ' SELECT b.id, ' . $t_sql_ranges . ' AS date_range'
. ' 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'
. ' WHERE b.status >= :int_st_resolved'
. ' AND h.old_value < :int_st_resolved'
. ' AND h.new_value >= :int_st_resolved'
. ' AND h.date_modified > :mint_ime'
$t_sql_inner = 'SELECT CASE WHEN h.type = :hist_type_new THEN :action_open'
. ' WHEN h.type = :hist_type_upd AND h.old_value >= :status AND h.new_value < :status THEN :action_open'
. ' WHEN h.type = :hist_type_upd AND h.old_value < :status AND h.new_value >= :status THEN :action_close'
. ' ELSE null END AS action, date_modified'
. ' FROM {bug_history} h JOIN {bug} b ON b.id = h.bug_id'
. ' WHERE h.date_modified > :mint_ime'
. ' AND ( h.type = :hist_type_new OR h.type = :hist_type_upd AND h.field_name = :hist_field )'
. ' AND ' . $t_specific_where;
$t_query->bind( array (
'hist_type' => NORMAL_TYPE,
'hist_type_upd' => NORMAL_TYPE,
'hist_type_new' => NEW_BUG,
'hist_field' => 'status',
'int_st_resolved' => (int)$t_resolved,
'status' => (string)$t_resolved,
'action_open' => 'O',
'action_close' => 'C',
'mint_ime' => $t_now - $t_prev_days * SECONDS_PER_DAY
) );
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 .= ' ) subquery GROUP BY date_range';
$t_query->sql( $t_sql );

$t_count_array = array();
foreach( $t_date_array as $t_ix => $t_value ) {
$t_count_array[$t_ix] = 0;
}
# count is accumulated
$t_count = 0;
while( $t_row = $t_query->fetch() ) {
$t_index = $t_row['date_range'];
if( $t_index >= 0 ) {
$t_count += $t_row['range_count'];
$t_count_array[$t_index] = $t_count;
}
}
return $t_count_array;
}

/**
* Calculate the number of "open" issues actions in the last X days.
* This includes each issue submission, and it's succesive reopen transitions.
* A filter can be used to limit the visibility.
*
* @param array $p_date_array An array of integers representing days is passed in.
* @param array $p_filter Filter array.
* @return array Accumulated count for each day range
*/
function summary_by_dates_open_bug_count( array $p_date_array, array $p_filter = null ) {
$t_project_id = helper_get_current_project();
$t_specific_where = helper_project_specific_where( $t_project_id );
$t_resolved = config_get( 'bug_resolved_status_threshold' );

$t_date_array = array_values( $p_date_array );
sort( $t_date_array );
$t_query = new DBQuery();

$t_prev_days = 0;
$t_now = db_now();
$t_sql_ranges = 'CASE';
foreach( $t_date_array as $t_ix => $t_days ) {
$c_days = (int)$t_days;
$t_range_start = $t_now - $c_days * SECONDS_PER_DAY + 1;
$t_range_end = $t_now - $t_prev_days * SECONDS_PER_DAY;
$t_sql_ranges .= ' WHEN h.date_modified'
. ' BETWEEN ' . $t_query->param( $t_range_start )
. ' AND ' . $t_query->param( $t_range_end )
. ' THEN ' . $t_ix;
$t_prev_days = $c_days;
}
$t_sql_ranges .= ' ELSE -1 END';

$t_sql = 'SELECT date_range, COUNT( id ) AS range_count FROM ('
. ' SELECT b.id, ' . $t_sql_ranges . ' AS date_range'
. ' FROM {bug} b LEFT JOIN {bug_history} h ON b.id = h.bug_id '
. ' WHERE ( h.type = :type_new'
. ' OR h.type = :type_st AND h.field_name = :field_st'
. ' AND h.old_value >= :int_st_resolved AND h.new_value < :int_st_resolved'
. ' ) AND h.date_modified > :mint_ime'
. ' AND ' . $t_specific_where;
$t_query->bind( array (
'type_new' => NEW_BUG,
'type_st' => NORMAL_TYPE,
'field_st' => 'status',
'int_st_resolved' => (int)$t_resolved,
'mint_ime' => $t_now - $t_prev_days * SECONDS_PER_DAY
) );
if( !empty( $p_filter ) ) {
$t_subquery = filter_cache_subquery( $p_filter );
$t_sql .= ' AND b.id IN :filter';
$t_sql_inner .= ' AND b.id IN :filter';
$t_query->bind( 'filter', $t_subquery );
}
$t_sql .= ' ) subquery GROUP BY date_range';

$t_sql = 'SELECT action, date_range, COUNT(*) AS range_count FROM'
. ' ( SELECT action, ' . $t_sql_ranges . ' AS date_range'
. ' FROM (' . $t_sql_inner . ') sub_actions'
. ' WHERE action IS NOT NULL ) sub_count'
. ' GROUP BY action, date_range ORDER BY date_range, action';
$t_query->sql( $t_sql );

# initialize the result array to 0
$t_count_array = array();
foreach( $t_date_array as $t_ix => $t_value ) {
$t_count_array[$t_ix] = 0;
$t_count_array['open'][$t_ix] = 0;
$t_count_array['close'][$t_ix] = 0;
}
# count is accumulated
$t_count = 0;
# count is accumulated, and date ranges are ordered in the result
$t_count_open = 0;
$t_count_closed = 0;
while( $t_row = $t_query->fetch() ) {
$t_index = $t_row['date_range'];
$t_index = (int)$t_row['date_range'];
if( $t_index >= 0 ) {
$t_count += $t_row['range_count'];
$t_count_array[$t_index] = $t_count;
switch( $t_row['action'] ) {
case 'O':
$t_count_open += $t_row['range_count'];
$t_count_array['open'][$t_index] = $t_count_open;
break;
case 'C':
$t_count_closed += $t_row['range_count'];
$t_count_array['close'][$t_index] = $t_count_closed;
}
}
}
return $t_count_array;
Expand All @@ -1433,8 +1398,9 @@ function summary_print_by_date( array $p_date_array, array $p_filter = null ) {
$t_date_array = array_values( $p_date_array );
sort( $t_date_array );

$t_open_count_array = summary_by_dates_open_bug_count( $t_date_array, $p_filter );
$t_resolved_count_array = summary_by_dates_resolved_bug_count( $t_date_array, $p_filter );
$t_by_dates_count = summary_by_dates_bug_count( $t_date_array, $p_filter );
$t_open_count_array = $t_by_dates_count['open'];
$t_resolved_count_array = $t_by_dates_count['close'];

foreach( $t_date_array as $t_ix => $t_days ) {
$t_new_count = $t_open_count_array[$t_ix];
Expand Down

0 comments on commit 89eef28

Please sign in to comment.