From 9c1600f10ff2df3c7b92ba2462c17bbd91402983 Mon Sep 17 00:00:00 2001 From: Tyler Bannister Date: Fri, 11 May 2012 15:02:56 -0400 Subject: [PATCH 1/5] MDL-30643 - Improved stats generation SQL queries. - Added temporary log tables to reduce log search times. - Added additional output to weekly and monthly stat generation --- lib/statslib.php | 667 ++++++++++++++++++++++++++++++----------------- 1 file changed, 423 insertions(+), 244 deletions(-) diff --git a/lib/statslib.php b/lib/statslib.php index 6b2220fbe25..c10e0f5f765 100644 --- a/lib/statslib.php +++ b/lib/statslib.php @@ -71,31 +71,56 @@ define('STATS_MODE_GENERAL',1); define('STATS_MODE_DETAILED',2); define('STATS_MODE_RANKED',3); // admins only - ranks courses +// Output string when nodebug is on +define('STATS_PLACEHOLDER_OUTPUT', '.'); + /** * Print daily cron progress * @param string $ident */ -function stats_daily_progress($ident) { +function stats_progress($ident) { static $start = 0; static $init = 0; if ($ident == 'init') { - $init = $start = time(); + $init = $start = microtime(true); return; } - $elapsed = time() - $start; - $start = time(); + $elapsed = round(microtime(true) - $start); + $start = microtime(true); if (debugging('', DEBUG_ALL)) { mtrace("$ident:$elapsed ", ''); } else { - mtrace('.', ''); + mtrace(STATS_PLACEHOLDER_OUTPUT, ''); } } +/** + * Execute individual daily statistics queries + * + * @param string $sql The query to run + * @return boolean success + */ +function stats_run_query($sql, $parameters) { + global $DB; + + try { + $DB->execute($sql, $parameters); + } catch (dml_exception $e) { + + if (debugging('', DEBUG_ALL)) { + mtrace($e->getMessage()); + } + return false; + } + return true; +} + /** * Execute daily statistics gathering + * * @param int $maxdays maximum number of days to be processed * @return boolean success */ @@ -117,7 +142,7 @@ function stats_cron_daily($maxdays=1) { // Note: This will work fine for sites running cron each 4 hours or less (hopefully, 99.99% of sites). MDL-16709 // check to make sure we're due to run, at least 20 hours after last run - if (isset($CFG->statslastexecution) and ((time() - 20*60*60) < $CFG->statslastexecution)) { + if (isset($CFG->statslastexecution) && ((time() - 20*60*60) < $CFG->statslastexecution)) { mtrace("...preventing stats to run, last execution was less than 20 hours ago."); return false; // also check that we are a max of 4 hours after scheduled time, stats won't run after that @@ -156,14 +181,23 @@ function stats_cron_daily($maxdays=1) { mtrace("Running daily statistics gathering, starting at $timestart:"); - $days = 0; - $failed = false; // failed stats flag + $days = 0; + $total = 0; + $failed = false; // failed stats flag + $timeout = false; - while ($now > $nextmidnight) { + if (!stats_temp_table_create()) { + $days = 1; + $failed = true; + } + mtrace("Temporary tables created"); + + $totalactiveusers = $DB->count_records('user', array('deleted' => '0')); + + while (!$failed && ($now > $nextmidnight)) { if ($days >= $maxdays) { - mtrace("...stopping early, reached maximum number of $maxdays days - will continue next time."); - set_cron_lock('statsrunning', null); - return false; + $timeout = true; + break; } $days++; @@ -176,53 +210,57 @@ function stats_cron_daily($maxdays=1) { $daystart = time(); - $timesql = "l.time >= $timestart AND l.time < $nextmidnight"; - $timesql1 = "l1.time >= $timestart AND l1.time < $nextmidnight"; - $timesql2 = "l2.time >= $timestart AND l2.time < $nextmidnight"; + stats_progress('init'); - stats_daily_progress('init'); - - - /// find out if any logs available for this day - $sql = "SELECT 'x' - FROM {log} l - WHERE $timesql"; - $logspresent = $DB->get_records_sql($sql, null, 0, 1); - - /// process login info first - $sql = "INSERT INTO {stats_user_daily} (stattype, timeend, courseid, userid, statsreads) - - SELECT 'logins', timeend, courseid, userid, count(statsreads) - FROM ( - SELECT $nextmidnight AS timeend, ".SITEID." AS courseid, l.userid, l.id AS statsreads - FROM {log} l - WHERE action = 'login' AND $timesql - ) inline_view - GROUP BY timeend, courseid, userid - HAVING count(statsreads) > 0"; - - if ($logspresent and !$DB->execute($sql)) { + if (!stats_temp_table_fill($timestart, $nextmidnight)) { $failed = true; break; } - stats_daily_progress('1'); + + stats_progress('in'); + + // Find out if any logs available for this day + $sql = "SELECT 'x' FROM {temp_log1} l"; + $logspresent = $DB->get_records_sql($sql, null, 0, 1); + + // Calculate the number of active users today + $sql = 'SELECT COUNT(DISTINCT u.id) + FROM {user} u + JOIN {temp_log1} l ON l.userid = u.id + WHERE u.deleted = 0'; + $dailyactiveusers = $DB->count_records_sql($sql); + + // Process login info first + // Note: PostgreSQL doesn't like aliases in HAVING clauses + $sql = "INSERT INTO {stats_user_daily} + (stattype, timeend, courseid, userid, statsreads) + + SELECT 'logins', $nextmidnight AS timeend, ".SITEID." AS courseid, + userid, COUNT(id) AS statsreads + FROM {temp_log1} l + WHERE action = 'login' + GROUP BY timeend, courseid, userid + HAVING COUNT(id) > 0"; + + if ($logspresent && !stats_run_query($sql)) { + $failed = true; + break; + } + + stats_progress('1'); $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'logins' AS stattype, $nextmidnight AS timeend, ".SITEID." as courseid, 0, - COALESCE((SELECT SUM(statsreads) - FROM {stats_user_daily} s1 - WHERE s1.stattype = 'logins' AND timeend = $nextmidnight), 0) AS stat1, - (SELECT COUNT('x') - FROM {stats_user_daily} s2 - WHERE s2.stattype = 'logins' AND timeend = $nextmidnight) AS stat2" . - $DB->sql_null_from_clause(); + SELECT 'logins' AS stattype, $nextmidnight AS timeend, ".SITEID." AS courseid, 0, + COALESCE(SUM(statsreads), 0) as stat1, COUNT('x') as stat2 + FROM {stats_user_daily} + WHERE stattype = 'logins' AND timeend = $nextmidnight"; - if ($logspresent and !$DB->execute($sql)) { + if ($logspresent && !stats_run_query($sql)) { $failed = true; break; } - stats_daily_progress('2'); + stats_progress('2'); // Enrolments and active enrolled users @@ -237,342 +275,351 @@ function stats_cron_daily($maxdays=1) { $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'enrolments', timeend, courseid, roleid, COUNT(DISTINCT userid), 0 - FROM ( - SELECT $nextmidnight AS timeend, e.courseid, ra.roleid, ue.userid - FROM {role_assignments} ra - JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) - JOIN {enrol} e ON e.courseid = c.instanceid - JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid) - ) inline_view - GROUP BY timeend, courseid, roleid"; + SELECT 'enrolments' AS stattype, $nextmidnight AS timeend, e.courseid, ra.roleid, + COUNT(DISTINCT ue.userid) AS stat1, 0 AS stat2 + FROM {role_assignments} ra + JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) + JOIN {enrol} e ON e.courseid = c.instanceid + JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid) + GROUP BY courseid, roleid"; - if (!$DB->execute($sql, array('courselevel'=>CONTEXT_COURSE))) { + if (!stats_run_query($sql, array('courselevel'=>CONTEXT_COURSE))) { $failed = true; break; } - stats_daily_progress('3'); + stats_progress('3'); // using table alias in UPDATE does not work in pg < 8.2 $sql = "UPDATE {stats_daily} - SET stat2 = (SELECT COUNT(DISTINCT ra.userid) - FROM {role_assignments} ra - JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) - JOIN {enrol} e ON e.courseid = c.instanceid - JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid) - WHERE ra.roleid = {stats_daily}.roleid AND - e.courseid = {stats_daily}.courseid AND - EXISTS (SELECT 'x' - FROM {log} l - WHERE l.course = {stats_daily}.courseid AND - l.userid = ra.userid AND $timesql)) - WHERE {stats_daily}.stattype = 'enrolments' AND - {stats_daily}.timeend = $nextmidnight AND - {stats_daily}.courseid IN - (SELECT DISTINCT l.course - FROM {log} l - WHERE $timesql)"; + SET stat2 = ( - if (!$DB->execute($sql, array('courselevel'=>CONTEXT_COURSE))) { + SELECT COUNT(DISTINCT ra.userid) + FROM {role_assignments} ra + JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) + JOIN {enrol} e ON e.courseid = c.instanceid + JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid) + WHERE ra.roleid = {stats_daily}.roleid + AND e.courseid = {stats_daily}.courseid + AND EXISTS ( + + SELECT 'x' + FROM {temp_log1} l + WHERE l.course = {stats_daily}.courseid + AND l.userid = ra.userid + ) + ) + + WHERE {stats_daily}.stattype = 'enrolments' + AND {stats_daily}.timeend = $nextmidnight + AND {stats_daily}.courseid IN ( + + SELECT DISTINCT course FROM {temp_log2} + )"; + + if (!stats_run_query($sql, array('courselevel'=>CONTEXT_COURSE))) { $failed = true; break; } - stats_daily_progress('4'); + stats_progress('4'); - /// now get course total enrolments (roleid==0) - except frontpage + // Now get course total enrolments (roleid==0) - except frontpage $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'enrolments', timeend, id, nroleid, COUNT(DISTINCT userid), 0 - FROM ( - SELECT $nextmidnight AS timeend, e.courseid AS id, 0 AS nroleid, ue.userid - FROM {enrol} e - JOIN {user_enrolments} ue ON ue.enrolid = e.id - ) inline_view - GROUP BY timeend, id, nroleid + SELECT 'enrolments', $nextmidnight AS timeend, e.courseid AS courseid, 0 AS roleid, + COUNT(DISTINCT userid) AS stat1, 0 AS stat2 + FROM {enrol} e + JOIN {user_enrolments} ue ON ue.enrolid = e.id + GROUP BY courseid HAVING COUNT(DISTINCT userid) > 0"; - if ($logspresent and !$DB->execute($sql)) { + if ($logspresent && !stats_run_query($sql)) { $failed = true; break; } - stats_daily_progress('5'); + stats_progress('5'); $sql = "UPDATE {stats_daily} - SET stat2 = (SELECT COUNT(DISTINCT ue.userid) - FROM {enrol} e - JOIN {user_enrolments} ue ON ue.enrolid = e.id - WHERE e.courseid = {stats_daily}.courseid AND - EXISTS (SELECT 'x' - FROM {log} l - WHERE l.course = {stats_daily}.courseid AND - l.userid = ue.userid AND $timesql)) - WHERE {stats_daily}.stattype = 'enrolments' AND - {stats_daily}.timeend = $nextmidnight AND - {stats_daily}.roleid = 0 AND - {stats_daily}.courseid IN - (SELECT l.course - FROM {log} l - WHERE $timesql AND l.course <> ".SITEID.")"; + SET stat2 = ( - if ($logspresent and !$DB->execute($sql, array())) { + SELECT COUNT(DISTINCT ue.userid) + FROM {enrol} e + JOIN {user_enrolments} ue ON ue.enrolid = e.id + WHERE e.courseid = {stats_daily}.courseid + AND EXISTS ( + + SELECT 'x' + FROM {temp_log1} l + WHERE l.course = {stats_daily}.courseid + AND l.userid = ue.userid + ) + ) + + WHERE {stats_daily}.stattype = 'enrolments' + AND {stats_daily}.timeend = $nextmidnight + AND {stats_daily}.roleid = 0 + AND {stats_daily}.courseid IN ( + + SELECT l.course + FROM {temp_log2} l + WHERE l.course <> ".SITEID.")"; + + if ($logspresent && !stats_run_query($sql, array())) { $failed = true; break; } - stats_daily_progress('6'); + stats_progress('6'); - /// frontapge(==site) enrolments total + // Frontpage(==site) enrolments total $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'enrolments', $nextmidnight, ".SITEID.", 0, - (SELECT COUNT('x') - FROM {user} u - WHERE u.deleted = 0) AS stat1, - (SELECT COUNT(DISTINCT u.id) - FROM {user} u - JOIN {log} l ON l.userid = u.id - WHERE u.deleted = 0 AND $timesql) AS stat2" . + SELECT 'enrolments', $nextmidnight, ".SITEID.", 0, $totalactiveusers AS stat1, + $dailyactiveusers AS stat2" . $DB->sql_null_from_clause(); - if ($logspresent and !$DB->execute($sql)) { + if ($logspresent && !stats_run_query($sql)) { $failed = true; break; } - stats_daily_progress('7'); + stats_progress('7'); - /// Default frontpage role enrolments are all site users (not deleted) + // Default frontpage role enrolments are all site users (not deleted) if ($defaultfproleid) { // first remove default frontpage role counts if created by previous query $sql = "DELETE FROM {stats_daily} - WHERE stattype = 'enrolments' AND courseid = ".SITEID." AND - roleid = $defaultfproleid AND timeend = $nextmidnight"; - if ($logspresent and !$DB->execute($sql)) { + WHERE stattype = 'enrolments' + AND courseid = ".SITEID." + AND roleid = $defaultfproleid + AND timeend = $nextmidnight"; + if ($logspresent && !stats_run_query($sql)) { $failed = true; break; } - stats_daily_progress('8'); + stats_progress('8'); $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'enrolments', $nextmidnight, ".SITEID.", $defaultfproleid, - (SELECT COUNT('x') - FROM {user} u - WHERE u.deleted = 0) AS stat1, - (SELECT COUNT(DISTINCT u.id) - FROM {user} u - JOIN {log} l ON l.userid = u.id - WHERE u.deleted = 0 AND $timesql) AS stat2" . + SELECT 'enrolments', $nextmidnight, ".SITEID.", $defaultfproleid, + $totalactiveusers AS stat1, $dailyactiveusers AS stat2" . $DB->sql_null_from_clause();; - if ($logspresent and !$DB->execute($sql)) { + if ($logspresent && !stats_run_query($sql)) { $failed = true; break; } - stats_daily_progress('9'); + stats_progress('9'); } else { - stats_daily_progress('x'); - stats_daily_progress('x'); + stats_progress('x'); + stats_progress('x'); } - /// individual user stats (including not-logged-in) in each course, this is slow - reuse this data if possible list($viewactionssql, $params1) = $DB->get_in_or_equal($viewactions, SQL_PARAMS_NAMED, 'view'); list($postactionssql, $params2) = $DB->get_in_or_equal($postactions, SQL_PARAMS_NAMED, 'post'); $sql = "INSERT INTO {stats_user_daily} (stattype, timeend, courseid, userid, statsreads, statswrites) - SELECT 'activity' AS stattype, $nextmidnight AS timeend, d.courseid, d.userid, - (SELECT COUNT('x') - FROM {log} l - WHERE l.userid = d.userid AND - l.course = d.courseid AND $timesql AND - l.action $viewactionssql) AS statsreads, - (SELECT COUNT('x') - FROM {log} l - WHERE l.userid = d.userid AND - l.course = d.courseid AND $timesql AND - l.action $postactionssql) AS statswrites - FROM (SELECT DISTINCT u.id AS userid, l.course AS courseid - FROM {user} u, {log} l - WHERE u.id = l.userid AND $timesql - UNION - SELECT 0 AS userid, ".SITEID." AS courseid" . $DB->sql_null_from_clause() . ") d"; - // can not use group by here because pg can not handle it :-( + SELECT 'activity' AS stattype, $nextmidnight AS timeend, course AS courseid, userid, + SUM(CASE WHEN action $viewactionssql THEN 1 ELSE 0 END) AS statsreads, + SUM(CASE WHEN action $postactionssql THEN 1 ELSE 0 END) AS statswrites + FROM {temp_log1} l + WHERE !(course = 0 AND userid = 0) + GROUP BY userid, courseid"; - if ($logspresent and !$DB->execute($sql, array_merge($params1, $params2))) { + if ($logspresent && !stats_run_query($sql, array_merge($params1, $params2))) { $failed = true; break; } - stats_daily_progress('10'); + stats_progress('10'); /// how many view/post actions in each course total $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity' AS stattype, $nextmidnight AS timeend, c.id AS courseid, 0, - (SELECT COUNT('x') - FROM {log} l1 - WHERE l1.course = c.id AND l1.action $viewactionssql AND - $timesql1) AS stat1, - (SELECT COUNT('x') - FROM {log} l2 - WHERE l2.course = c.id AND l2.action $postactionssql AND - $timesql2) AS stat2 - FROM {course} c - WHERE EXISTS (SELECT 'x' - FROM {log} l - WHERE l.course = c.id and $timesql)"; + SUM(CASE WHEN l.action $viewactionssql THEN 1 ELSE 0 END) AS stat1, + SUM(CASE WHEN l.action $postactionssql THEN 1 ELSE 0 END) AS stat2 + FROM {course} c, {temp_log1} l + WHERE l.course = c.id + GROUP BY courseid"; - if ($logspresent and !$DB->execute($sql, array_merge($params1, $params2))) { + if ($logspresent && !stats_run_query($sql, array_merge($params1, $params2))) { $failed = true; break; } - stats_daily_progress('11'); + stats_progress('11'); /// how many view actions for each course+role - excluding guests and frontpage $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'activity', timeend, courseid, roleid, SUM(statsreads), SUM(statswrites) + SELECT 'activity', $nextmidnight AS timeend, courseid, roleid, SUM(statsreads), SUM(statswrites) FROM ( - SELECT $nextmidnight AS timeend, pl.courseid, pl.roleid, sud.statsreads, sud.statswrites - FROM {stats_user_daily} sud, - (SELECT DISTINCT ra.userid, ra.roleid, e.courseid - FROM {role_assignments} ra - JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) - JOIN {enrol} e ON e.courseid = c.instanceid - JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid) - WHERE ra.roleid <> $guestrole AND - ra.userid <> $guest - ) pl - WHERE sud.userid = pl.userid AND - sud.courseid = pl.courseid AND - sud.timeend = $nextmidnight AND + + SELECT pl.courseid, pl.roleid, sud.statsreads, sud.statswrites + FROM {stats_user_daily} sud, ( + + SELECT DISTINCT ra.userid, ra.roleid, e.courseid + FROM {role_assignments} ra + JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) + JOIN {enrol} e ON e.courseid = c.instanceid + JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid) + WHERE ra.roleid <> $guestrole + AND ra.userid <> $guest + ) pl + WHERE sud.userid = pl.userid + AND sud.courseid = pl.courseid + AND sud.timeend = $nextmidnight AND sud.stattype='activity' ) inline_view + GROUP BY timeend, courseid, roleid HAVING SUM(statsreads) > 0 OR SUM(statswrites) > 0"; - if ($logspresent and !$DB->execute($sql, array('courselevel'=>CONTEXT_COURSE))) { + if ($logspresent && !stats_run_query($sql, array('courselevel'=>CONTEXT_COURSE))) { $failed = true; break; } - stats_daily_progress('12'); + stats_progress('12'); /// how many view actions from guests only in each course - excluding frontpage /// normal users may enter course with temporary guest access too $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'activity', timeend, courseid, nroleid, SUM(statsreads), SUM(statswrites) + SELECT 'activity', $nextmidnight AS timeend, courseid, $guestrole AS roleid, + SUM(statsreads), SUM(statswrites) FROM ( - SELECT $nextmidnight AS timeend, sud.courseid, $guestrole AS nroleid, sud.statsreads, sud.statswrites - FROM {stats_user_daily} sud - WHERE sud.timeend = $nextmidnight AND sud.courseid <> ".SITEID." AND - sud.stattype='activity' AND - (sud.userid = $guest OR sud.userid - NOT IN (SELECT ue.userid - FROM {user_enrolments} ue - JOIN {enrol} e ON ue.enrolid = e.id - WHERE e.courseid = sud.courseid)) + + SELECT sud.courseid, sud.statsreads, sud.statswrites + FROM {stats_user_daily} sud + WHERE sud.timeend = $nextmidnight + AND sud.courseid <> ".SITEID." + AND sud.stattype='activity' + AND (sud.userid = $guest OR sud.userid NOT IN ( + + SELECT ue.userid + FROM {user_enrolments} ue + JOIN {enrol} e ON ue.enrolid = e.id + WHERE e.courseid = sud.courseid + )) ) inline_view - GROUP BY timeend, courseid, nroleid + + GROUP BY timeend, courseid, roleid HAVING SUM(statsreads) > 0 OR SUM(statswrites) > 0"; - if ($logspresent and !$DB->execute($sql, array())) { + if ($logspresent && !stats_run_query($sql, array())) { $failed = true; break; } - stats_daily_progress('13'); + stats_progress('13'); /// how many view actions for each role on frontpage - excluding guests, not-logged-in and default frontpage role $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'activity', timeend, courseid, roleid, SUM(statsreads), SUM(statswrites) + SELECT 'activity', $nextmidnight AS timeend, courseid, roleid, + SUM(statsreads), SUM(statswrites) FROM ( - SELECT $nextmidnight AS timeend, pl.courseid, pl.roleid, sud.statsreads, sud.statswrites - FROM {stats_user_daily} sud, - (SELECT DISTINCT ra.userid, ra.roleid, c.instanceid AS courseid - FROM {role_assignments} ra - JOIN {context} c ON c.id = ra.contextid - WHERE ra.contextid = :fpcontext AND - ra.roleid <> $defaultfproleid AND - ra.roleid <> $guestrole AND - ra.userid <> $guest - ) pl - WHERE sud.userid = pl.userid AND - sud.courseid = pl.courseid AND - sud.timeend = $nextmidnight AND - sud.stattype='activity' + SELECT pl.courseid, pl.roleid, sud.statsreads, sud.statswrites + FROM {stats_user_daily} sud, ( + + SELECT DISTINCT ra.userid, ra.roleid, c.instanceid AS courseid + FROM {role_assignments} ra + JOIN {context} c ON c.id = ra.contextid + WHERE ra.contextid = :fpcontext + AND ra.roleid <> $defaultfproleid + AND ra.roleid <> $guestrole + AND ra.userid <> $guest + ) pl + WHERE sud.userid = pl.userid + AND sud.courseid = pl.courseid + AND sud.timeend = $nextmidnight + AND sud.stattype='activity' ) inline_view + GROUP BY timeend, courseid, roleid HAVING SUM(statsreads) > 0 OR SUM(statswrites) > 0"; - if ($logspresent and !$DB->execute($sql, array('fpcontext'=>$fpcontext->id))) { + if ($logspresent && !stats_run_query($sql, array('fpcontext'=>$fpcontext->id))) { $failed = true; break; } - stats_daily_progress('14'); + stats_progress('14'); /// how many view actions for default frontpage role on frontpage only $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'activity', timeend, courseid, nroleid, SUM(statsreads), SUM(statswrites) + SELECT 'activity', timeend, courseid, $defaultfproleid AS roleid, + SUM(statsreads), SUM(statswrites) FROM ( - SELECT sud.timeend AS timeend, sud.courseid, $defaultfproleid AS nroleid, sud.statsreads, sud.statswrites - FROM {stats_user_daily} sud - WHERE sud.timeend = :nextm AND sud.courseid = :siteid AND - sud.stattype='activity' AND - sud.userid <> $guest AND sud.userid <> 0 AND sud.userid - NOT IN (SELECT ra.userid - FROM {role_assignments} ra - WHERE ra.roleid <> $guestrole AND - ra.roleid <> $defaultfproleid AND ra.contextid = :fpcontext) + SELECT sud.timeend AS timeend, sud.courseid, sud.statsreads, sud.statswrites + FROM {stats_user_daily} sud + WHERE sud.timeend = :nextm AND sud.courseid = :siteid + AND sud.stattype='activity' + AND sud.userid <> $guest + AND sud.userid <> 0 + AND sud.userid NOT IN ( + + SELECT ra.userid + FROM {role_assignments} ra + WHERE ra.roleid <> $guestrole + AND ra.roleid <> $defaultfproleid + AND ra.contextid = :fpcontext) ) inline_view - GROUP BY timeend, courseid, nroleid + + GROUP BY timeend, courseid, roleid HAVING SUM(statsreads) > 0 OR SUM(statswrites) > 0"; - if ($logspresent and !$DB->execute($sql, array('fpcontext'=>$fpcontext->id, 'siteid'=>SITEID, 'nextm'=>$nextmidnight))) { + if ($logspresent && !stats_run_query($sql, array('fpcontext'=>$fpcontext->id, 'siteid'=>SITEID, 'nextm'=>$nextmidnight))) { $failed = true; break; } - stats_daily_progress('15'); + stats_progress('15'); /// how many view actions for guests or not-logged-in on frontpage $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'activity', timeend, courseid, nroleid, SUM(statsreads), SUM(statswrites) + SELECT 'activity', $nextmidnight AS timeend, ".SITEID." AS courseid, $guestrole AS roleid, + SUM(statsreads), SUM(statswrites) FROM ( - SELECT $nextmidnight AS timeend, ".SITEID." AS courseid, $guestrole AS nroleid, pl.statsreads, pl.statswrites - FROM ( - SELECT sud.statsreads, sud.statswrites - FROM {stats_user_daily} sud - WHERE (sud.userid = $guest OR sud.userid = 0) AND - sud.timeend = $nextmidnight AND sud.courseid = ".SITEID." AND - sud.stattype='activity' - ) pl - ) inline_view - GROUP BY timeend, courseid, nroleid + + SELECT sud.statsreads, sud.statswrites + FROM {stats_user_daily} sud + WHERE (sud.userid = $guest OR sud.userid = 0) + AND sud.timeend = $nextmidnight + AND sud.courseid = ".SITEID." + AND sud.stattype='activity' + ) inline_view + + GROUP BY timeend, courseid, roleid HAVING SUM(statsreads) > 0 OR SUM(statswrites) > 0"; - if ($logspresent and !$DB->execute($sql)) { + if ($logspresent && !stats_run_query($sql)) { $failed = true; break; } - stats_daily_progress('16'); + stats_progress('16'); + + stats_temp_table_clean(); + + stats_progress('out'); // remember processed days set_config('statslastdaily', $nextmidnight); - mtrace(" finished until $nextmidnight: ".userdate($nextmidnight)." (in ".(time()-$daystart)." s)"); + $elapsed = time()-$daystart; + mtrace(" finished until $nextmidnight: ".userdate($nextmidnight)." (in $elapsed s)"); + $total += $elapsed; $timestart = $nextmidnight; $nextmidnight = stats_get_next_day_start($nextmidnight); } + stats_temp_table_drop(); + set_cron_lock('statsrunning', null); if ($failed) { @@ -580,8 +627,12 @@ function stats_cron_daily($maxdays=1) { mtrace("...error occurred, completed $days days of statistics."); return false; + } else if ($timeout) { + mtrace("...stopping early, reached maximum number of $maxdays days - will continue next time."); + return false; + } else { - mtrace("...completed $days days of statistics."); + mtrace("...completed $days days of statistics in {$total} s."); return true; } } @@ -634,6 +685,9 @@ function stats_cron_weekly() { $logtimesql = "l.time >= $timestart AND l.time < $nextstartweek"; $stattimesql = "timeend > $timestart AND timeend <= $nextstartweek"; + $weekstart = time(); + stats_progress('init'); + /// process login info first $sql = "INSERT INTO {stats_user_weekly} (stattype, timeend, courseid, userid, statsreads) @@ -644,10 +698,12 @@ function stats_cron_weekly() { WHERE action = 'login' AND $logtimesql ) inline_view GROUP BY timeend, courseid, userid - HAVING count(statsreads) > 0"; + HAVING COUNT(statsreads) > 0"; $DB->execute($sql); + stats_progress('1'); + $sql = "INSERT INTO {stats_weekly} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'logins' AS stattype, $nextstartweek AS timeend, ".SITEID." as courseid, 0, @@ -661,6 +717,7 @@ function stats_cron_weekly() { $DB->execute($sql); + stats_progress('2'); /// now enrolments averages $sql = "INSERT INTO {stats_weekly} (stattype, timeend, courseid, roleid, stat1, stat2) @@ -675,6 +732,7 @@ function stats_cron_weekly() { $DB->execute($sql); + stats_progress('3'); /// activity read/write averages $sql = "INSERT INTO {stats_weekly} (stattype, timeend, courseid, roleid, stat1, stat2) @@ -689,6 +747,7 @@ function stats_cron_weekly() { $DB->execute($sql); + stats_progress('4'); /// user read/write averages $sql = "INSERT INTO {stats_user_weekly} (stattype, timeend, courseid, userid, statsreads, statswrites) @@ -703,8 +762,11 @@ function stats_cron_weekly() { $DB->execute($sql); + stats_progress('5'); + set_config('statslastweekly', $nextstartweek); - mtrace(" finished until $nextstartweek: ".userdate($nextstartweek)); + $elapsed = time()-$weekstart; + mtrace(" finished until $nextstartweek: ".userdate($nextstartweek) ." ( in $elapsed s)"); $timestart = $nextstartweek; $nextstartweek = stats_get_next_week_start($nextstartweek); @@ -765,6 +827,9 @@ function stats_cron_monthly() { $logtimesql = "l.time >= $timestart AND l.time < $nextstartmonth"; $stattimesql = "timeend > $timestart AND timeend <= $nextstartmonth"; + $monthstart = time(); + stats_progress('init'); + /// process login info first $sql = "INSERT INTO {stats_user_monthly} (stattype, timeend, courseid, userid, statsreads) @@ -778,6 +843,8 @@ function stats_cron_monthly() { $DB->execute($sql); + stats_progress('1'); + $sql = "INSERT INTO {stats_monthly} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'logins' AS stattype, $nextstartmonth AS timeend, ".SITEID." as courseid, 0, @@ -791,6 +858,7 @@ function stats_cron_monthly() { $DB->execute($sql); + stats_progress('2'); /// now enrolments averages $sql = "INSERT INTO {stats_monthly} (stattype, timeend, courseid, roleid, stat1, stat2) @@ -805,6 +873,7 @@ function stats_cron_monthly() { $DB->execute($sql); + stats_progress('3'); /// activity read/write averages $sql = "INSERT INTO {stats_monthly} (stattype, timeend, courseid, roleid, stat1, stat2) @@ -819,6 +888,7 @@ function stats_cron_monthly() { $DB->execute($sql); + stats_progress('4'); /// user read/write averages $sql = "INSERT INTO {stats_user_monthly} (stattype, timeend, courseid, userid, statsreads, statswrites) @@ -833,8 +903,11 @@ function stats_cron_monthly() { $DB->execute($sql); + stats_progress('5'); + set_config('statslastmonthly', $nextstartmonth); - mtrace(" finished until $nextstartmonth: ".userdate($nextstartmonth)); + $elapsed = time() - $monthstart; + mtrace(" finished until $nextstartmonth: ".userdate($nextstartmonth) ." (in $elapsed s)"); $timestart = $nextstartmonth; $nextstartmonth = stats_get_next_month_start($nextstartmonth); @@ -1462,3 +1535,109 @@ function stats_check_uptodate($courseid=0) { //return error as string return get_string('statscatchupmode','error',$a); } + +/** + * Create temporary tables to speed up log generation + */ +function stats_temp_table_create() { + global $CFG, $DB; + + $dbman = $DB->get_manager(); // We are going to use database_manager services + + stats_temp_table_drop(); + + $log = new xmldb_table('temp_log1'); + + $log->add_field('id', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, null); + $log->add_field('userid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, null); + $log->add_field('course', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, null); + $log->add_field('action', XMLDB_TYPE_CHAR, '40', null, XMLDB_NOTNULL, null, null); + + $log->add_key('primary', XMLDB_KEY_PRIMARY, array('id')); + $log->add_index('temp_tl_course_ix', XMLDB_INDEX_NOTUNIQUE, array('course')); + $log->add_index('temp_tl_act_ix', XMLDB_INDEX_NOTUNIQUE, array('action')); + $log->add_index('temp_tl_user_ix', XMLDB_INDEX_NOTUNIQUE, array('userid')); + $log->add_index('temp_tl_usecouact_ix', XMLDB_INDEX_NOTUNIQUE, array('userid','course','action')); + + try { + $dbman->create_temp_table($log); + + $log->name = 'temp_log2'; + + $dbman->create_temp_table($log); + + } catch (Exception $e) { + mtrace("Temporary table creation failed!"); + return false; + } + + return true; +} + +/** + * Deletes summary logs table for stats calculation + */ +function stats_temp_table_drop() { + global $DB; + + $dbman = $DB->get_manager(); + + $tables = array('temp_log1', 'temp_log2'); + + foreach ($tables as $name) { + + if ($dbman->table_exists($name)) { + $table = new xmldb_table($name); + + try { + $dbman->drop_temp_table($table); + } catch (Exception $e) { + mtrace("Error occured while dropping temporary tables!"); + } + } + } +} + +/** + * Fills the temporary stats tables with new data + * + * @param timestart timestamp of the start time of logs view + * @param timeend timestamp of the end time of logs view + * @returns boolen success (true) or failure(false) + */ +function stats_temp_table_fill($timestart, $timeend) { + global $DB; + + $sql = 'INSERT INTO {temp_log1} (userid, course, action) + + SELECT userid, course, action FROM {log} l + WHERE l.time >= ? AND l.time < ?'; + + $DB->execute($sql); + + $sql = 'INSERT INTO {temp_log2} (userid, course, action) + + SELECT userid, course, action FROM {temp_log1}'; + + $DB->execute($sql); + + return true; +} + + +/** + * Deletes summary logs table for stats calculation + * + * @returns boolen success (true) or failure(false) + */ +function stats_temp_table_clean() { + global $DB; + + $tables = array('temp_log1', 'temp_log2'); + + foreach ($tables as $name) { + $DB->delete_record($name); + } + + return true; +} From 0934f5c304b77aee595a7582c43b4bd2d538a4d6 Mon Sep 17 00:00:00 2001 From: Tyler Bannister Date: Fri, 18 May 2012 10:07:48 -0400 Subject: [PATCH 2/5] MDL-30643 - Added temporary tables to store the stats results until generation is complete. --- lib/statslib.php | 131 +++++++++++++++++++++++++++++++++-------------- 1 file changed, 93 insertions(+), 38 deletions(-) diff --git a/lib/statslib.php b/lib/statslib.php index c10e0f5f765..7975c00a49f 100644 --- a/lib/statslib.php +++ b/lib/statslib.php @@ -232,7 +232,7 @@ function stats_cron_daily($maxdays=1) { // Process login info first // Note: PostgreSQL doesn't like aliases in HAVING clauses - $sql = "INSERT INTO {stats_user_daily} + $sql = "INSERT INTO {temp_stats_user_daily} (stattype, timeend, courseid, userid, statsreads) SELECT 'logins', $nextmidnight AS timeend, ".SITEID." AS courseid, @@ -249,11 +249,11 @@ function stats_cron_daily($maxdays=1) { stats_progress('1'); - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'logins' AS stattype, $nextmidnight AS timeend, ".SITEID." AS courseid, 0, COALESCE(SUM(statsreads), 0) as stat1, COUNT('x') as stat2 - FROM {stats_user_daily} + FROM {temp_stats_user_daily} WHERE stattype = 'logins' AND timeend = $nextmidnight"; if ($logspresent && !stats_run_query($sql)) { @@ -273,7 +273,7 @@ function stats_cron_daily($maxdays=1) { // in that case, we'll count non-deleted users. // - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'enrolments' AS stattype, $nextmidnight AS timeend, e.courseid, ra.roleid, COUNT(DISTINCT ue.userid) AS stat1, 0 AS stat2 @@ -290,7 +290,7 @@ function stats_cron_daily($maxdays=1) { stats_progress('3'); // using table alias in UPDATE does not work in pg < 8.2 - $sql = "UPDATE {stats_daily} + $sql = "UPDATE {temp_stats_daily} SET stat2 = ( SELECT COUNT(DISTINCT ra.userid) @@ -298,13 +298,13 @@ function stats_cron_daily($maxdays=1) { JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) JOIN {enrol} e ON e.courseid = c.instanceid JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid) - WHERE ra.roleid = {stats_daily}.roleid - AND e.courseid = {stats_daily}.courseid + WHERE ra.roleid = {temp_stats_daily}.roleid + AND e.courseid = {temp_stats_daily}.courseid AND EXISTS ( SELECT 'x' FROM {temp_log1} l - WHERE l.course = {stats_daily}.courseid + WHERE l.course = {temp_stats_daily}.courseid AND l.userid = ra.userid ) ) @@ -323,7 +323,7 @@ function stats_cron_daily($maxdays=1) { stats_progress('4'); // Now get course total enrolments (roleid==0) - except frontpage - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'enrolments', $nextmidnight AS timeend, e.courseid AS courseid, 0 AS roleid, COUNT(DISTINCT userid) AS stat1, 0 AS stat2 @@ -338,26 +338,26 @@ function stats_cron_daily($maxdays=1) { } stats_progress('5'); - $sql = "UPDATE {stats_daily} + $sql = "UPDATE {temp_stats_daily} SET stat2 = ( SELECT COUNT(DISTINCT ue.userid) FROM {enrol} e JOIN {user_enrolments} ue ON ue.enrolid = e.id - WHERE e.courseid = {stats_daily}.courseid + WHERE e.courseid = {temp_stats_daily}.courseid AND EXISTS ( SELECT 'x' FROM {temp_log1} l - WHERE l.course = {stats_daily}.courseid + WHERE l.course = {temp_stats_daily}.courseid AND l.userid = ue.userid ) ) - WHERE {stats_daily}.stattype = 'enrolments' - AND {stats_daily}.timeend = $nextmidnight - AND {stats_daily}.roleid = 0 - AND {stats_daily}.courseid IN ( + WHERE {temp_stats_daily}.stattype = 'enrolments' + AND {temp_stats_daily}.timeend = $nextmidnight + AND {temp_stats_daily}.roleid = 0 + AND {temp_stats_daily}.courseid IN ( SELECT l.course FROM {temp_log2} l @@ -370,7 +370,7 @@ function stats_cron_daily($maxdays=1) { stats_progress('6'); // Frontpage(==site) enrolments total - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'enrolments', $nextmidnight, ".SITEID.", 0, $totalactiveusers AS stat1, $dailyactiveusers AS stat2" . @@ -386,18 +386,19 @@ function stats_cron_daily($maxdays=1) { if ($defaultfproleid) { // first remove default frontpage role counts if created by previous query $sql = "DELETE - FROM {stats_daily} + FROM {temp_stats_daily} WHERE stattype = 'enrolments' AND courseid = ".SITEID." AND roleid = $defaultfproleid AND timeend = $nextmidnight"; + if ($logspresent && !stats_run_query($sql)) { $failed = true; break; } stats_progress('8'); - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'enrolments', $nextmidnight, ".SITEID.", $defaultfproleid, $totalactiveusers AS stat1, $dailyactiveusers AS stat2" . @@ -418,7 +419,7 @@ function stats_cron_daily($maxdays=1) { /// individual user stats (including not-logged-in) in each course, this is slow - reuse this data if possible list($viewactionssql, $params1) = $DB->get_in_or_equal($viewactions, SQL_PARAMS_NAMED, 'view'); list($postactionssql, $params2) = $DB->get_in_or_equal($postactions, SQL_PARAMS_NAMED, 'post'); - $sql = "INSERT INTO {stats_user_daily} (stattype, timeend, courseid, userid, statsreads, statswrites) + $sql = "INSERT INTO {temp_stats_user_daily} (stattype, timeend, courseid, userid, statsreads, statswrites) SELECT 'activity' AS stattype, $nextmidnight AS timeend, course AS courseid, userid, SUM(CASE WHEN action $viewactionssql THEN 1 ELSE 0 END) AS statsreads, @@ -435,7 +436,7 @@ function stats_cron_daily($maxdays=1) { /// how many view/post actions in each course total - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity' AS stattype, $nextmidnight AS timeend, c.id AS courseid, 0, SUM(CASE WHEN l.action $viewactionssql THEN 1 ELSE 0 END) AS stat1, @@ -453,13 +454,13 @@ function stats_cron_daily($maxdays=1) { /// how many view actions for each course+role - excluding guests and frontpage - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity', $nextmidnight AS timeend, courseid, roleid, SUM(statsreads), SUM(statswrites) FROM ( SELECT pl.courseid, pl.roleid, sud.statsreads, sud.statswrites - FROM {stats_user_daily} sud, ( + FROM {temp_stats_user_daily} sud, ( SELECT DISTINCT ra.userid, ra.roleid, e.courseid FROM {role_assignments} ra @@ -471,8 +472,8 @@ function stats_cron_daily($maxdays=1) { ) pl WHERE sud.userid = pl.userid AND sud.courseid = pl.courseid - AND sud.timeend = $nextmidnight AND - sud.stattype='activity' + AND sud.timeend = $nextmidnight + AND sud.stattype='activity' ) inline_view GROUP BY timeend, courseid, roleid @@ -487,14 +488,14 @@ function stats_cron_daily($maxdays=1) { /// how many view actions from guests only in each course - excluding frontpage /// normal users may enter course with temporary guest access too - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity', $nextmidnight AS timeend, courseid, $guestrole AS roleid, SUM(statsreads), SUM(statswrites) FROM ( SELECT sud.courseid, sud.statsreads, sud.statswrites - FROM {stats_user_daily} sud + FROM {temp_stats_user_daily} sud WHERE sud.timeend = $nextmidnight AND sud.courseid <> ".SITEID." AND sud.stattype='activity' @@ -518,13 +519,13 @@ function stats_cron_daily($maxdays=1) { /// how many view actions for each role on frontpage - excluding guests, not-logged-in and default frontpage role - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity', $nextmidnight AS timeend, courseid, roleid, SUM(statsreads), SUM(statswrites) FROM ( SELECT pl.courseid, pl.roleid, sud.statsreads, sud.statswrites - FROM {stats_user_daily} sud, ( + FROM {temp_stats_user_daily} sud, ( SELECT DISTINCT ra.userid, ra.roleid, c.instanceid AS courseid FROM {role_assignments} ra @@ -551,14 +552,15 @@ function stats_cron_daily($maxdays=1) { /// how many view actions for default frontpage role on frontpage only - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity', timeend, courseid, $defaultfproleid AS roleid, SUM(statsreads), SUM(statswrites) FROM ( SELECT sud.timeend AS timeend, sud.courseid, sud.statsreads, sud.statswrites - FROM {stats_user_daily} sud - WHERE sud.timeend = :nextm AND sud.courseid = :siteid + FROM {temp_stats_user_daily} sud + WHERE sud.timeend = :nextm + AND sud.courseid = :siteid AND sud.stattype='activity' AND sud.userid <> $guest AND sud.userid <> 0 @@ -581,14 +583,14 @@ function stats_cron_daily($maxdays=1) { stats_progress('15'); /// how many view actions for guests or not-logged-in on frontpage - $sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) + $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity', $nextmidnight AS timeend, ".SITEID." AS courseid, $guestrole AS roleid, SUM(statsreads), SUM(statswrites) FROM ( SELECT sud.statsreads, sud.statswrites - FROM {stats_user_daily} sud + FROM {temp_stats_user_daily} sud WHERE (sud.userid = $guest OR sud.userid = 0) AND sud.timeend = $nextmidnight AND sud.courseid = ".SITEID." @@ -1559,6 +1561,34 @@ function stats_temp_table_create() { $log->add_index('temp_tl_user_ix', XMLDB_INDEX_NOTUNIQUE, array('userid')); $log->add_index('temp_tl_usecouact_ix', XMLDB_INDEX_NOTUNIQUE, array('userid','course','action')); + $user = new xmldb_table('temp_stats_daily'); + $user->add_field('courseid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + $user->add_field('roleid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + $user->add_field('stattype', XMLDB_TYPE_CHAR, '20', null, XMLDB_NOTNULL, null, 'activity'); + $user->add_field('timeend', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + $user->add_field('stat1', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + $user->add_field('stat2', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + + $user->add_index('temp_tsd_courseid_ix', XMLDB_INDEX_NOTUNIQUE, array('courseid')); + $user->add_index('temp_tsd_roleid_ix', XMLDB_INDEX_NOTUNIQUE, array('roleid')); + $user->add_index('temp_tsd_statype_ix', XMLDB_INDEX_NOTUNIQUE, array('stattype')); + $user->add_index('temp_tsd_timeend_ix', XMLDB_INDEX_NOTUNIQUE, array('timeend')); + + $daily = new xmldb_table('temp_stats_user_daily'); + $daily->add_field('courseid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + $daily->add_field('userid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + $daily->add_field('roleid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + $daily->add_field('timeend', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + $daily->add_field('statsreads', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + $daily->add_field('statswrites', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); + $daily->add_field('stattype', XMLDB_TYPE_CHAR, '30', null, XMLDB_NOTNULL, null, null); + + $daily->add_index('temp_tsud_courseid_ix', XMLDB_INDEX_NOTUNIQUE, array('courseid')); + $daily->add_index('temp_tsud_userid_ix', XMLDB_INDEX_NOTUNIQUE, array('userid')); + $daily->add_index('temp_tsud_roleid_ix', XMLDB_INDEX_NOTUNIQUE, array('roleid')); + $daily->add_index('temp_tsud_stattype_ix', XMLDB_INDEX_NOTUNIQUE, array('stattype')); + $daily->add_index('temp_tsud_timeend_ix', XMLDB_INDEX_NOTUNIQUE, array('timeend')); + try { $dbman->create_temp_table($log); @@ -1566,6 +1596,10 @@ function stats_temp_table_create() { $dbman->create_temp_table($log); + $dbman->create_temp_table($user); + + $dbman->create_temp_table($daily); + } catch (Exception $e) { mtrace("Temporary table creation failed!"); return false; @@ -1582,7 +1616,7 @@ function stats_temp_table_drop() { $dbman = $DB->get_manager(); - $tables = array('temp_log1', 'temp_log2'); + $tables = array('temp_log1', 'temp_log2', 'temp_stats_daily', 'temp_stats_user_daily'); foreach ($tables as $name) { @@ -1613,7 +1647,7 @@ function stats_temp_table_fill($timestart, $timeend) { SELECT userid, course, action FROM {log} l WHERE l.time >= ? AND l.time < ?'; - $DB->execute($sql); + $DB->execute($sql, array($timestart, $timeend)); $sql = 'INSERT INTO {temp_log2} (userid, course, action) @@ -1633,10 +1667,31 @@ function stats_temp_table_fill($timestart, $timeend) { function stats_temp_table_clean() { global $DB; - $tables = array('temp_log1', 'temp_log2'); + $sql = array(); + + $sql['up1'] = 'INSERT INTO {stats_daily} (courseid, roleid, stattype, timeend, stat1, stat2) + + SELECT courseid, roleid, stattype, timeend, stat1, stat2 FROM {temp_stats_daily}'; + + $sql['up2'] = 'INSERT INTO {stats_user_daily} + (courseid, userid, roleid, timeend, statsreads, statswrites, stattype) + + SELECT courseid, userid, roleid, timeend, statsreads, statswrites, stattype + FROM {temp_stats_user_daily}'; + + foreach ($sql as $id => $query) { + try { + $DB->execute($query); + } catch (Exception $e) { + mtrace("Error during table cleanup!"); + return false; + } + } + + $tables = array('temp_log1', 'temp_log2', 'temp_stats_daily', 'temp_stats_user_daily'); foreach ($tables as $name) { - $DB->delete_record($name); + $DB->delete_records($name); } return true; From 4614b0290526202d28a5d087376ba2f9c5b6103b Mon Sep 17 00:00:00 2001 From: Tyler Bannister Date: Fri, 3 Aug 2012 15:51:49 -0400 Subject: [PATCH 3/5] MDL-30643 - Added definition for new temporary table to install.xml. - Added code to generate tempoary tables from existing standard tables where possible. --- lib/db/install.xml | 19 ++++++- lib/statslib.php | 128 ++++++++++++++++++++++----------------------- 2 files changed, 81 insertions(+), 66 deletions(-) diff --git a/lib/db/install.xml b/lib/db/install.xml index aee878fddbc..d1cfa55916f 100644 --- a/lib/db/install.xml +++ b/lib/db/install.xml @@ -2882,7 +2882,7 @@ - +
@@ -2897,5 +2897,22 @@
+ + + + + + + + + + + + + + + + +
diff --git a/lib/statslib.php b/lib/statslib.php index 7975c00a49f..67a446d7399 100644 --- a/lib/statslib.php +++ b/lib/statslib.php @@ -111,10 +111,10 @@ function stats_run_query($sql, $parameters) { } catch (dml_exception $e) { if (debugging('', DEBUG_ALL)) { - mtrace($e->getMessage()); + mtrace($e->getMessage()); } - return false; - } + return false; + } return true; } @@ -217,7 +217,7 @@ function stats_cron_daily($maxdays=1) { break; } - stats_progress('in'); + stats_progress('0'); // Find out if any logs available for this day $sql = "SELECT 'x' FROM {temp_log1} l"; @@ -289,6 +289,7 @@ function stats_cron_daily($maxdays=1) { } stats_progress('3'); + // Set stat2 to the number distinct users with role assignments in the course that were active // using table alias in UPDATE does not work in pg < 8.2 $sql = "UPDATE {temp_stats_daily} SET stat2 = ( @@ -316,7 +317,7 @@ function stats_cron_daily($maxdays=1) { SELECT DISTINCT course FROM {temp_log2} )"; - if (!stats_run_query($sql, array('courselevel'=>CONTEXT_COURSE))) { + if ($logspresent && !stats_run_query($sql, array('courselevel'=>CONTEXT_COURSE))) { $failed = true; break; } @@ -338,6 +339,7 @@ function stats_cron_daily($maxdays=1) { } stats_progress('5'); + // Set stat 2 to the number of enrolled users who were active in the course $sql = "UPDATE {temp_stats_daily} SET stat2 = ( @@ -400,7 +402,7 @@ function stats_cron_daily($maxdays=1) { $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'enrolments', $nextmidnight, ".SITEID.", $defaultfproleid, + SELECT 'enrolments', $nextmidnight, ".SITEID.", $defaultfproleid, $totalactiveusers AS stat1, $dailyactiveusers AS stat2" . $DB->sql_null_from_clause();; @@ -416,7 +418,7 @@ function stats_cron_daily($maxdays=1) { } - /// individual user stats (including not-logged-in) in each course, this is slow - reuse this data if possible + /// individual user stats (including not-logged-in) in each course, this is slow - reuse this data if possible list($viewactionssql, $params1) = $DB->get_in_or_equal($viewactions, SQL_PARAMS_NAMED, 'view'); list($postactionssql, $params2) = $DB->get_in_or_equal($postactions, SQL_PARAMS_NAMED, 'post'); $sql = "INSERT INTO {temp_stats_user_daily} (stattype, timeend, courseid, userid, statsreads, statswrites) @@ -435,7 +437,7 @@ function stats_cron_daily($maxdays=1) { stats_progress('10'); - /// how many view/post actions in each course total + /// How many view/post actions in each course total $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity' AS stattype, $nextmidnight AS timeend, c.id AS courseid, 0, @@ -452,7 +454,7 @@ function stats_cron_daily($maxdays=1) { stats_progress('11'); - /// how many view actions for each course+role - excluding guests and frontpage + /// how many view actions for each course+role - excluding guests and frontpage $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) @@ -485,8 +487,8 @@ function stats_cron_daily($maxdays=1) { } stats_progress('12'); - /// how many view actions from guests only in each course - excluding frontpage - /// normal users may enter course with temporary guest access too + /// how many view actions from guests only in each course - excluding frontpage + /// normal users may enter course with temporary guest access too $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) @@ -518,7 +520,7 @@ function stats_cron_daily($maxdays=1) { stats_progress('13'); - /// how many view actions for each role on frontpage - excluding guests, not-logged-in and default frontpage role + /// How many view actions for each role on frontpage - excluding guests, not-logged-in and default frontpage role $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity', $nextmidnight AS timeend, courseid, roleid, @@ -551,7 +553,7 @@ function stats_cron_daily($maxdays=1) { stats_progress('14'); - /// how many view actions for default frontpage role on frontpage only + // How many view actions for default frontpage role on frontpage only $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity', timeend, courseid, $defaultfproleid AS roleid, @@ -582,7 +584,7 @@ function stats_cron_daily($maxdays=1) { } stats_progress('15'); - /// how many view actions for guests or not-logged-in on frontpage + // How many view actions for guests or not-logged-in on frontpage $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) SELECT 'activity', $nextmidnight AS timeend, ".SITEID." AS courseid, $guestrole AS roleid, @@ -626,11 +628,11 @@ function stats_cron_daily($maxdays=1) { if ($failed) { $days--; - mtrace("...error occurred, completed $days days of statistics."); + mtrace("...error occurred, completed $days days of statistics in {$total} s."); return false; } else if ($timeout) { - mtrace("...stopping early, reached maximum number of $maxdays days - will continue next time."); + mtrace("...stopping early, reached maximum number of $maxdays days ({$total} s) - will continue next time."); return false; } else { @@ -768,7 +770,7 @@ function stats_cron_weekly() { set_config('statslastweekly', $nextstartweek); $elapsed = time()-$weekstart; - mtrace(" finished until $nextstartweek: ".userdate($nextstartweek) ." ( in $elapsed s)"); + mtrace(" finished until $nextstartweek: ".userdate($nextstartweek) ." (in $elapsed s)"); $timestart = $nextstartweek; $nextstartweek = stats_get_next_week_start($nextstartweek); @@ -1548,60 +1550,56 @@ function stats_temp_table_create() { stats_temp_table_drop(); - $log = new xmldb_table('temp_log1'); + $xmlfile = $CFG->dirroot . '/lib/db/install.xml'; + $tempfile = $CFG->dirroot . '/lib/db/temp_stats_log_template.xml'; + $tables = array(); - $log->add_field('id', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, null); - $log->add_field('userid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, null); - $log->add_field('course', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, null); - $log->add_field('action', XMLDB_TYPE_CHAR, '40', null, XMLDB_NOTNULL, null, null); + // Allows for the additional xml files to be used (if necessary) + $files = array( + $xmlfile => array( + 'stats_daily' => array('temp_stats_daily'), + 'stats_user_daily' => array('temp_stats_user_daily'), + 'temp_log_template' => array('temp_log1', 'temp_log2'), + ), + ); - $log->add_key('primary', XMLDB_KEY_PRIMARY, array('id')); - $log->add_index('temp_tl_course_ix', XMLDB_INDEX_NOTUNIQUE, array('course')); - $log->add_index('temp_tl_act_ix', XMLDB_INDEX_NOTUNIQUE, array('action')); - $log->add_index('temp_tl_user_ix', XMLDB_INDEX_NOTUNIQUE, array('userid')); - $log->add_index('temp_tl_usecouact_ix', XMLDB_INDEX_NOTUNIQUE, array('userid','course','action')); + foreach ($files as $file => $contents) { - $user = new xmldb_table('temp_stats_daily'); - $user->add_field('courseid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - $user->add_field('roleid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - $user->add_field('stattype', XMLDB_TYPE_CHAR, '20', null, XMLDB_NOTNULL, null, 'activity'); - $user->add_field('timeend', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - $user->add_field('stat1', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - $user->add_field('stat2', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - - $user->add_index('temp_tsd_courseid_ix', XMLDB_INDEX_NOTUNIQUE, array('courseid')); - $user->add_index('temp_tsd_roleid_ix', XMLDB_INDEX_NOTUNIQUE, array('roleid')); - $user->add_index('temp_tsd_statype_ix', XMLDB_INDEX_NOTUNIQUE, array('stattype')); - $user->add_index('temp_tsd_timeend_ix', XMLDB_INDEX_NOTUNIQUE, array('timeend')); + $xmldb_file = new xmldb_file($file); + if (!$xmldb_file->fileExists()) { + throw new ddl_exception('ddlxmlfileerror', null, 'File does not exist'); + } + $loaded = $xmldb_file->loadXMLStructure(); + if (!$loaded || !$xmldb_file->isLoaded()) { + throw new ddl_exception('ddlxmlfileerror', null, 'not loaded??'); + } + $xmldb_structure = $xmldb_file->getStructure(); - $daily = new xmldb_table('temp_stats_user_daily'); - $daily->add_field('courseid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - $daily->add_field('userid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - $daily->add_field('roleid', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - $daily->add_field('timeend', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - $daily->add_field('statsreads', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - $daily->add_field('statswrites', XMLDB_TYPE_INTEGER, '10', XMLDB_UNSIGNED, XMLDB_NOTNULL, null, 0); - $daily->add_field('stattype', XMLDB_TYPE_CHAR, '30', null, XMLDB_NOTNULL, null, null); + foreach ($contents as $template => $names) { + $table = $xmldb_structure->getTable($template); - $daily->add_index('temp_tsud_courseid_ix', XMLDB_INDEX_NOTUNIQUE, array('courseid')); - $daily->add_index('temp_tsud_userid_ix', XMLDB_INDEX_NOTUNIQUE, array('userid')); - $daily->add_index('temp_tsud_roleid_ix', XMLDB_INDEX_NOTUNIQUE, array('roleid')); - $daily->add_index('temp_tsud_stattype_ix', XMLDB_INDEX_NOTUNIQUE, array('stattype')); - $daily->add_index('temp_tsud_timeend_ix', XMLDB_INDEX_NOTUNIQUE, array('timeend')); + if (is_null($table)) { + throw new ddl_exception('ddlunknowntable', null, 'The table '. $name .' is not defined in the file '. $xmlfile); + } + $table->setNext(null); + $table->setPrevious(null); + + foreach ($names as $name) { + $named = clone $table; + $named->setName($name); + $tables[$name] = $named; + } + } + } try { - $dbman->create_temp_table($log); - $log->name = 'temp_log2'; - - $dbman->create_temp_table($log); - - $dbman->create_temp_table($user); - - $dbman->create_temp_table($daily); + foreach ($tables as $table) { + $dbman->create_temp_table($table); + } } catch (Exception $e) { - mtrace("Temporary table creation failed!"); + mtrace('Temporary table creation failed: '. $e->getMessage()); return false; } @@ -1624,7 +1622,7 @@ function stats_temp_table_drop() { $table = new xmldb_table($name); try { - $dbman->drop_temp_table($table); + $dbman->drop_table($table); } catch (Exception $e) { mtrace("Error occured while dropping temporary tables!"); } @@ -1642,10 +1640,10 @@ function stats_temp_table_drop() { function stats_temp_table_fill($timestart, $timeend) { global $DB; - $sql = 'INSERT INTO {temp_log1} (userid, course, action) + $sql = "INSERT INTO {temp_log1} (userid, course, action) - SELECT userid, course, action FROM {log} l - WHERE l.time >= ? AND l.time < ?'; + SELECT userid, course, action FROM {log} + WHERE time >= ? AND time < ?"; $DB->execute($sql, array($timestart, $timeend)); From c0f00c5fbae6156640b95dba2bbcc1a41e1d5857 Mon Sep 17 00:00:00 2001 From: Tyler Bannister Date: Fri, 3 Aug 2012 15:53:27 -0400 Subject: [PATCH 4/5] MDL-30643 - Added statslib test file. - Tests daily stats and daily stats related functions. --- lib/statslib.php | 15 +- lib/tests/fixtures/statslib-test00.xml | 35 ++ lib/tests/fixtures/statslib-test01.xml | 116 +++++ lib/tests/fixtures/statslib-test02.xml | 117 +++++ lib/tests/fixtures/statslib-test03.xml | 151 +++++++ lib/tests/fixtures/statslib-test04.xml | 157 +++++++ lib/tests/fixtures/statslib-test05.xml | 151 +++++++ lib/tests/fixtures/statslib-test06.xml | 157 +++++++ lib/tests/fixtures/statslib-test07.xml | 166 +++++++ lib/tests/fixtures/statslib-test08.xml | 132 ++++++ lib/tests/fixtures/statslib-test09.xml | 129 ++++++ lib/tests/fixtures/statslib-test10.xml | 107 +++++ lib/tests/statslib_test.php | 581 +++++++++++++++++++++++++ 13 files changed, 2009 insertions(+), 5 deletions(-) create mode 100644 lib/tests/fixtures/statslib-test00.xml create mode 100644 lib/tests/fixtures/statslib-test01.xml create mode 100644 lib/tests/fixtures/statslib-test02.xml create mode 100644 lib/tests/fixtures/statslib-test03.xml create mode 100644 lib/tests/fixtures/statslib-test04.xml create mode 100644 lib/tests/fixtures/statslib-test05.xml create mode 100644 lib/tests/fixtures/statslib-test06.xml create mode 100644 lib/tests/fixtures/statslib-test07.xml create mode 100644 lib/tests/fixtures/statslib-test08.xml create mode 100644 lib/tests/fixtures/statslib-test09.xml create mode 100644 lib/tests/fixtures/statslib-test10.xml create mode 100644 lib/tests/statslib_test.php diff --git a/lib/statslib.php b/lib/statslib.php index 67a446d7399..eee36ec741f 100644 --- a/lib/statslib.php +++ b/lib/statslib.php @@ -217,12 +217,16 @@ function stats_cron_daily($maxdays=1) { break; } - stats_progress('0'); - // Find out if any logs available for this day $sql = "SELECT 'x' FROM {temp_log1} l"; $logspresent = $DB->get_records_sql($sql, null, 0, 1); + if ($logspresent) { + // Insert blank record to force Query 10 to generate additional row when no logs for + // the site with userid 0 exist. Added for backwards compatibility. + $DB->insert_record('temp_log1', array('userid' => 0, 'course' => SITEID, 'action' => '')); + } + // Calculate the number of active users today $sql = 'SELECT COUNT(DISTINCT u.id) FROM {user} u @@ -230,6 +234,8 @@ function stats_cron_daily($maxdays=1) { WHERE u.deleted = 0'; $dailyactiveusers = $DB->count_records_sql($sql); + stats_progress('0'); + // Process login info first // Note: PostgreSQL doesn't like aliases in HAVING clauses $sql = "INSERT INTO {temp_stats_user_daily} @@ -427,7 +433,6 @@ function stats_cron_daily($maxdays=1) { SUM(CASE WHEN action $viewactionssql THEN 1 ELSE 0 END) AS statsreads, SUM(CASE WHEN action $postactionssql THEN 1 ELSE 0 END) AS statswrites FROM {temp_log1} l - WHERE !(course = 0 AND userid = 0) GROUP BY userid, courseid"; if ($logspresent && !stats_run_query($sql, array_merge($params1, $params2))) { @@ -1640,10 +1645,10 @@ function stats_temp_table_drop() { function stats_temp_table_fill($timestart, $timeend) { global $DB; - $sql = "INSERT INTO {temp_log1} (userid, course, action) + $sql = 'INSERT INTO {temp_log1} (userid, course, action) SELECT userid, course, action FROM {log} - WHERE time >= ? AND time < ?"; + WHERE time >= ? AND time < ?'; $DB->execute($sql, array($timestart, $timeend)); diff --git a/lib/tests/fixtures/statslib-test00.xml b/lib/tests/fixtures/statslib-test00.xml new file mode 100644 index 00000000000..f41e8f34d62 --- /dev/null +++ b/lib/tests/fixtures/statslib-test00.xml @@ -0,0 +1,35 @@ + + + + + time + userid + course + action +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + [course1_id] + [end_no_logs] + 5 + enrolments + 1 + 0 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype +
+
diff --git a/lib/tests/fixtures/statslib-test01.xml b/lib/tests/fixtures/statslib-test01.xml new file mode 100644 index 00000000000..bcfc903a56a --- /dev/null +++ b/lib/tests/fixtures/statslib-test01.xml @@ -0,0 +1,116 @@ + + + + + time + userid + course + action + + [start_1] + [guest_id] + [site_id] + view + +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + + [site_id] + [end] + 0 + logins + 0 + 0 + + + + [course1_id] + [end] + [student_roleid] + enrolments + 1 + 0 + + + + [course1_id] + [end] + 0 + enrolments + 1 + 0 + + + + [site_id] + [end] + 0 + enrolments + 4 + 1 + + + + [site_id] + [end] + [frontpage_roleid] + enrolments + 4 + 1 + + + + [site_id] + [end] + 0 + activity + 1 + 0 + + + + [site_id] + [end] + [guest_roleid] + activity + 1 + 0 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype + + + [site_id] + [guest_id] + 0 + [end] + 1 + 0 + activity + + + + [site_id] + 0 + 0 + [end] + 0 + 0 + activity + +
+
diff --git a/lib/tests/fixtures/statslib-test02.xml b/lib/tests/fixtures/statslib-test02.xml new file mode 100644 index 00000000000..1b1cd351751 --- /dev/null +++ b/lib/tests/fixtures/statslib-test02.xml @@ -0,0 +1,117 @@ + + + + + time + userid + course + action + + [start_1] + [user1_id] + [site_id] + login + +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + + [site_id] + [end] + 0 + logins + 1 + 1 + + + + [course1_id] + [end] + [student_roleid] + enrolments + 1 + 0 + + + + [course1_id] + [end] + 0 + enrolments + 1 + 0 + + + + [site_id] + [end] + 0 + enrolments + 4 + 1 + + + + [site_id] + [end] + [frontpage_roleid] + enrolments + 4 + 1 + + + + [site_id] + [end] + 0 + activity + 0 + 0 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype + + + [site_id] + [user1_id] + 0 + [end] + 1 + 0 + logins + + + + [site_id] + [user1_id] + 0 + [end] + 0 + 0 + activity + + + + [site_id] + 0 + 0 + [end] + 0 + 0 + activity + +
+
diff --git a/lib/tests/fixtures/statslib-test03.xml b/lib/tests/fixtures/statslib-test03.xml new file mode 100644 index 00000000000..db0c2a0344e --- /dev/null +++ b/lib/tests/fixtures/statslib-test03.xml @@ -0,0 +1,151 @@ + + + + + time + userid + course + action + + [start_1] + [guest_id] + [site_id] + login + + + [start_2] + [guest_id] + [course1_id] + view + +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + + [site_id] + [end] + 0 + logins + 1 + 1 + + + + [course1_id] + [end] + [student_roleid] + enrolments + 1 + 0 + + + + [course1_id] + [end] + 0 + enrolments + 1 + 0 + + + + [site_id] + [end] + 0 + enrolments + 4 + 1 + + + + [site_id] + [end] + [frontpage_roleid] + enrolments + 4 + 1 + + + + [site_id] + [end] + 0 + activity + 0 + 0 + + + + [course1_id] + [end] + 0 + activity + 1 + 0 + + + + [course1_id] + [end] + [guest_roleid] + activity + 1 + 0 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype + + + [site_id] + [guest_id] + 0 + [end] + 1 + 0 + logins + + + + [course1_id] + [guest_id] + 0 + [end] + 1 + 0 + activity + + + + [site_id] + [guest_id] + 0 + [end] + 0 + 0 + activity + + + + [site_id] + 0 + 0 + [end] + 0 + 0 + activity + +
+
diff --git a/lib/tests/fixtures/statslib-test04.xml b/lib/tests/fixtures/statslib-test04.xml new file mode 100644 index 00000000000..efe9e2ace0d --- /dev/null +++ b/lib/tests/fixtures/statslib-test04.xml @@ -0,0 +1,157 @@ + + + + + time + userid + course + action + + [start_1] + [guest_id] + [site_id] + login + + + [start_2] + [guest_id] + [course1_id] + view + + + [start_3] + [guest_id] + [course1_id] + add post + +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + + [site_id] + [end] + 0 + logins + 1 + 1 + + + + [course1_id] + [end] + [student_roleid] + enrolments + 1 + 0 + + + + [course1_id] + [end] + 0 + enrolments + 1 + 0 + + + + [site_id] + [end] + 0 + enrolments + 4 + 1 + + + + [site_id] + [end] + [frontpage_roleid] + enrolments + 4 + 1 + + + + [site_id] + [end] + 0 + activity + 0 + 0 + + + + [course1_id] + [end] + 0 + activity + 1 + 1 + + + + [course1_id] + [end] + [guest_roleid] + activity + 1 + 1 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype + + + [site_id] + [guest_id] + 0 + [end] + 1 + 0 + logins + + + + [course1_id] + [guest_id] + 0 + [end] + 1 + 1 + activity + + + + [site_id] + [guest_id] + 0 + [end] + 0 + 0 + activity + + + + [site_id] + 0 + 0 + [end] + 0 + 0 + activity + +
+
diff --git a/lib/tests/fixtures/statslib-test05.xml b/lib/tests/fixtures/statslib-test05.xml new file mode 100644 index 00000000000..b839f74f78b --- /dev/null +++ b/lib/tests/fixtures/statslib-test05.xml @@ -0,0 +1,151 @@ + + + + + time + userid + course + action + + [start_1] + [user1_id] + [site_id] + login + + + [start_2] + [user1_id] + [course1_id] + view + +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + + [site_id] + [end] + 0 + logins + 1 + 1 + + + + [course1_id] + [end] + [student_roleid] + enrolments + 1 + 1 + + + + [course1_id] + [end] + 0 + enrolments + 1 + 1 + + + + [site_id] + [end] + 0 + enrolments + 4 + 1 + + + + [site_id] + [end] + [frontpage_roleid] + enrolments + 4 + 1 + + + + [site_id] + [end] + 0 + activity + 0 + 0 + + + + [course1_id] + [end] + 0 + activity + 1 + 0 + + + + [course1_id] + [end] + [student_roleid] + activity + 1 + 0 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype + + + [site_id] + [user1_id] + 0 + [end] + 1 + 0 + logins + + + + [course1_id] + [user1_id] + 0 + [end] + 1 + 0 + activity + + + + [site_id] + [user1_id] + 0 + [end] + 0 + 0 + activity + + + + [site_id] + 0 + 0 + [end] + 0 + 0 + activity + +
+
diff --git a/lib/tests/fixtures/statslib-test06.xml b/lib/tests/fixtures/statslib-test06.xml new file mode 100644 index 00000000000..04017102ee5 --- /dev/null +++ b/lib/tests/fixtures/statslib-test06.xml @@ -0,0 +1,157 @@ + + + + + time + userid + course + action + + [start_1] + [user1_id] + [site_id] + login + + + [start_2] + [user1_id] + [course1_id] + view + + + [start_3] + [user1_id] + [course1_id] + add post + +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + + [site_id] + [end] + 0 + logins + 1 + 1 + + + + [course1_id] + [end] + [student_roleid] + enrolments + 1 + 1 + + + + [course1_id] + [end] + 0 + enrolments + 1 + 1 + + + + [site_id] + [end] + 0 + enrolments + 4 + 1 + + + + [site_id] + [end] + [frontpage_roleid] + enrolments + 4 + 1 + + + + [site_id] + [end] + 0 + activity + 0 + 0 + + + + [course1_id] + [end] + 0 + activity + 1 + 1 + + + + [course1_id] + [end] + [student_roleid] + activity + 1 + 1 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype + + + [site_id] + [user1_id] + 0 + [end] + 1 + 0 + logins + + + + [course1_id] + [user1_id] + 0 + [end] + 1 + 1 + activity + + + + [site_id] + [user1_id] + 0 + [end] + 0 + 0 + activity + + + + [site_id] + 0 + 0 + [end] + 0 + 0 + activity + +
+
diff --git a/lib/tests/fixtures/statslib-test07.xml b/lib/tests/fixtures/statslib-test07.xml new file mode 100644 index 00000000000..86379b8b91d --- /dev/null +++ b/lib/tests/fixtures/statslib-test07.xml @@ -0,0 +1,166 @@ + + + + + time + userid + course + action + + [start_1] + [user2_id] + [site_id] + login + + + [start_2] + [user2_id] + [site_id] + view + + + [start_3] + [user2_id] + [course1_id] + view + +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + + [site_id] + [end] + 0 + logins + 1 + 1 + + + + [course1_id] + [end] + [student_roleid] + enrolments + 1 + 0 + + + + [course1_id] + [end] + 0 + enrolments + 1 + 0 + + + + [site_id] + [end] + 0 + enrolments + 4 + 1 + + + + [site_id] + [end] + [frontpage_roleid] + enrolments + 4 + 1 + + + + [site_id] + [end] + 0 + activity + 1 + 0 + + + + [course1_id] + [end] + 0 + activity + 1 + 0 + + + + [course1_id] + [end] + [guest_roleid] + activity + 1 + 0 + + + + [site_id] + [end] + [frontpage_roleid] + activity + 1 + 0 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype + + + [site_id] + [user2_id] + 0 + [end] + 1 + 0 + logins + + + + [course1_id] + [user2_id] + 0 + [end] + 1 + 0 + activity + + + + [site_id] + [user2_id] + 0 + [end] + 1 + 0 + activity + + + + [site_id] + 0 + 0 + [end] + 0 + 0 + activity + +
+
diff --git a/lib/tests/fixtures/statslib-test08.xml b/lib/tests/fixtures/statslib-test08.xml new file mode 100644 index 00000000000..62a90c91bf1 --- /dev/null +++ b/lib/tests/fixtures/statslib-test08.xml @@ -0,0 +1,132 @@ + + + + + time + userid + course + action + + [start_1] + [user1_id] + [site_id] + login + + + [start_2] + [user1_id] + [site_id] + view + +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + + [site_id] + [end] + 0 + logins + 1 + 1 + + + + [course1_id] + [end] + [student_roleid] + enrolments + 1 + 0 + + + + [course1_id] + [end] + 0 + enrolments + 1 + 0 + + + + [site_id] + [end] + 0 + enrolments + 4 + 1 + + + + [site_id] + [end] + [frontpage_roleid] + enrolments + 4 + 1 + + + + [site_id] + [end] + 0 + activity + 1 + 0 + + + + [site_id] + [end] + [frontpage_roleid] + activity + 1 + 0 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype + + + [site_id] + [user1_id] + 0 + [end] + 1 + 0 + logins + + + + [site_id] + [user1_id] + 0 + [end] + 1 + 0 + activity + + + + [site_id] + 0 + 0 + [end] + 0 + 0 + activity + +
+
diff --git a/lib/tests/fixtures/statslib-test09.xml b/lib/tests/fixtures/statslib-test09.xml new file mode 100644 index 00000000000..efe77b691d5 --- /dev/null +++ b/lib/tests/fixtures/statslib-test09.xml @@ -0,0 +1,129 @@ + + + + + time + userid + course + action + + [start_0] + [user1_id] + [site_id] + login + + + [start_1] + [user1_id] + [site_id] + login + + + [start_4] + [user1_id] + [site_id] + login + +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + + [site_id] + [end] + 0 + logins + 1 + 1 + + + + [course1_id] + [end] + [student_roleid] + enrolments + 1 + 0 + + + + [course1_id] + [end] + 0 + enrolments + 1 + 0 + + + + [site_id] + [end] + 0 + enrolments + 4 + 1 + + + + [site_id] + [end] + [frontpage_roleid] + enrolments + 4 + 1 + + + + [site_id] + [end] + 0 + activity + 1 + 0 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype + + + [site_id] + [user1_id] + 0 + [end] + 1 + 0 + logins + + + + [site_id] + [user1_id] + 0 + [end] + 0 + 0 + activity + + + + [site_id] + 0 + 0 + [end] + 0 + 0 + activity + +
+
diff --git a/lib/tests/fixtures/statslib-test10.xml b/lib/tests/fixtures/statslib-test10.xml new file mode 100644 index 00000000000..83d7fcc2c1f --- /dev/null +++ b/lib/tests/fixtures/statslib-test10.xml @@ -0,0 +1,107 @@ + + + + + time + userid + course + action + + [start_1] + [guest_id] + [site_id] + view + +
+ + courseid + timeend + roleid + stattype + stat1 + stat2 + + + [site_id] + [end] + 0 + logins + 0 + 0 + + + + [course1_id] + [end] + [student_roleid] + enrolments + 1 + 0 + + + + [course1_id] + [end] + 0 + enrolments + 1 + 0 + + + + [site_id] + [end] + 0 + enrolments + 4 + 1 + + + + [site_id] + [end] + 0 + activity + 1 + 0 + + + + [site_id] + [end] + [guest_roleid] + activity + 1 + 0 + +
+ + courseid + userid + roleid + timeend + statsreads + statswrites + stattype + + + [site_id] + [guest_id] + 0 + [end] + 1 + 0 + activity + + + + [site_id] + 0 + 0 + [end] + 0 + 0 + activity + +
+
diff --git a/lib/tests/statslib_test.php b/lib/tests/statslib_test.php new file mode 100644 index 00000000000..6c02d25999d --- /dev/null +++ b/lib/tests/statslib_test.php @@ -0,0 +1,581 @@ +. + +/** + * Tests for ../statslib.php + * + * @package core + * @subpackage stats + * @copyright 2012 Tyler Bannister + * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later + */ + +defined('MOODLE_INTERNAL') || die(); + +global $CFG; +require_once($CFG->libdir . '/adminlib.php'); +require_once($CFG->libdir . '/statslib.php'); + +/** + * Test functions that affect daily stats + */ +class statslib_daily_testcase extends advanced_testcase { + /** The student role ID **/ + const STID = 5; + + /** The day to use for testing **/ + const DAY = 1272700810; // 1272758400 + + /** @var array The list of temporary tables created for the statistic calculations **/ + protected $tables = array('temp_log1', 'temp_log2', 'temp_stats_daily', 'temp_stats_user_daily'); + + /** @var array The replacements to be used when loading XML files **/ + protected $replacements = null; + + /** + * Set up the database for tests + * + * This function is needed so that daily_log_provider has the before-test set up from setUp() + */ + public function setUpDB() { + global $DB; + + if ($DB->record_exists('user', array('username' => 'user1'))) { + return; + } + + $datagen = self::getDataGenerator(); + + $user1 = $datagen->create_user(array('username'=>'user1')); + $user2 = $datagen->create_user(array('username'=>'user2')); + + $course1 = $datagen->create_course(array('shortname'=>'course1')); + + $success = enrol_try_internal_enrol($course1->id, $user1->id, 5); + + if (! $success) { + trigger_error('User enrollment failed', E_USER_ERROR); + } + + $context = context_system::instance(); + role_assign(self::STID, $user2->id, $context->id); + + $this->generate_replacement_list(); + } + + /** + * Setup function + * - Allow changes to CFG->debug for testing purposes. + */ + protected function setUp() { + global $CFG; + parent::setUp(); + + // Settings to force statistic to run during testing + $CFG->timezone = 99; + $CFG->statsfirstrun = 'all'; + $CFG->statslastdaily = 0; + $CFG->statslastexecution = 0; + $CFG->statsruntimestarthour = date('H'); + $CFG->statsruntimestartminute = 0; + + $this->setUpDB(); + + $this->resetAfterTest(true); + } + + /** + * Function to setup database. + * + * @param array $dataset An array of tables including the log table. + */ + protected function prepare_db($dataset, $tables) { + global $DB; + + foreach ($tables as $tablename) { + $DB->delete_records($tablename); + + foreach ($dataset as $name => $table) { + + if ($tablename == $name) { + + $rows = $table->getRowCount(); + + for ($i = 0; $i < $rows; $i++) { + $row = $table->getRow($i); + + $DB->insert_record($tablename, $row, false, true); + } + } + } + } + } + + /** + * Load dataset from XML file + * + * @param string $file The name of the file to load + */ + protected function generate_replacement_list() { + global $CFG, $DB; + + if ($this->replacements !== null) { + return; + } + + $guest = $DB->get_record('user', array('id' => $CFG->siteguest)); + $user1 = $DB->get_record('user', array('username' => 'user1')); + $user2 = $DB->get_record('user', array('username' => 'user2')); + + if (($guest === false) || ($user1 === false) || ($user2 === false)) { + trigger_error('User setup incomplete', E_USER_ERROR); + } + + $site = $DB->get_record('course', array('id' => SITEID)); + $course1 = $DB->get_record('course', array('shortname' => 'course1')); + + if (($site === false) || ($course1 === false)) { + trigger_error('Course setup incomplete', E_USER_ERROR); + } + + $start = stats_get_base_daily(self::DAY + 3600); + $startnolog = stats_get_base_daily(stats_get_start_from('daily')); + $gr = get_guest_role(); + + $this->replacements = array( + // Start and end times + '[start_0]' => $start - 14410, // 4 hours before + '[start_1]' => $start + 14410, // 4 hours after + '[start_2]' => $start + 14420, + '[start_3]' => $start + 14430, + '[start_4]' => $start + 100800, // 28 hours after + '[end]' => stats_get_next_day_start($start), + '[end_no_logs]' => stats_get_next_day_start($startnolog), + + // User ids + '[guest_id]' => $guest->id, + '[user1_id]' => $user1->id, + '[user2_id]' => $user2->id, + + // Course ids + '[course1_id]' => $course1->id, + '[site_id]' => SITEID, + + // Role ids + '[frontpage_roleid]' => (int) $CFG->defaultfrontpageroleid, + '[guest_roleid]' => $gr->id, + '[student_roleid]' => self::STID, + ); + } + + /** + * Load dataset from XML file + * + * @param string $file The name of the file to load + */ + protected function load_xml_data_file($file) { + static $replacements = null; + + $raw = $this->createXMLDataSet($file); + $clean = new PHPUnit_Extensions_Database_DataSet_ReplacementDataSet($raw); + + foreach ($this->replacements as $placeholder => $value) { + $clean->addFullReplacement($placeholder, $value); + } + + $logs = new PHPUnit_Extensions_Database_DataSet_DataSetFilter($clean); + $logs->addIncludeTables(array('log')); + + $stats = new PHPUnit_Extensions_Database_DataSet_DataSetFilter($clean); + $stats->addIncludeTables(array('stats_daily', 'stats_user_daily')); + + return array($logs, $stats); + } + + /** + * Provides the log data for test_statslib_cron_daily + */ + public function daily_log_provider() { + global $CFG, $DB; + + $this->setUpDB(); + + $tests = array('00', '01', '02', '03', '04', '05', '06', '07', '08'); + + $dataset = array(); + + foreach ($tests as $test) { + $dataset[] = $this->load_xml_data_file(__DIR__."/fixtures/statslib-test{$test}.xml"); + } + + return $dataset; + } + + /** + * Compare the expected stats to those in the database. + * + * @param array $stats An array of arrays of arrays of both types of stats + */ + protected function verify_stats($expected) { + global $DB; + + // Note: We can not use $this->assertDataSetEqual($expected, $actual) because there's no + // $this->getConnection() in advanced_testcase. + + foreach ($expected as $type => $table) { + $records = $DB->get_records($type); + + $rows = $table->getRowCount(); + + $this->assertEquals($rows, sizeof($records), + 'Incorrect number of results returned for '. $type); + + for ($i = 0; $i < $rows; $i++) { + $row = $table->getRow($i); + $found = 0; + + foreach ($records as $key => $record) { + $record = (array) $record; + unset($record['id']); + $diff = array_merge(array_diff_assoc($row, $record), + array_diff_assoc($record, $row)); + + if (empty($diff)) { + $found = $key; + break; + } + } + $this->assertGreaterThan(0, $found, 'Expected log '. var_export($row, true) + ." was not found in $type ". var_export($records, true)); + unset($records[$found]); + } + } + } + + /** + * Test progress output when debug is on + */ + public function test_statslib_progress_debug() { + global $CFG; + + $CFG->debug = DEBUG_ALL; + $this->expectOutputString('1:0 '); + stats_progress('init'); + stats_progress('1'); + } + + /** + * Test progress output when debug is off + */ + public function test_statslib_progress_no_debug() { + global $CFG; + + $CFG->debug = DEBUG_NONE; + $this->expectOutputString('.'); + stats_progress('init'); + stats_progress('1'); + } + + /** + * Test the function that gets the start date from the config + */ + public function test_statslib_get_start_from() { + global $CFG, $DB; + + $dataset = $this->load_xml_data_file(__DIR__."/fixtures/statslib-test01.xml"); + + $time = time(); + $DB->delete_records('log'); + + $CFG->statsfirstrun = 'all'; + // Allow 1 second difference in case we cross a second boundary. + $this->assertLessThanOrEqual(1, stats_get_start_from('daily') - ($time - (3 * 24 * 3600)), 'All start time'); + + $this->prepare_db($dataset[0], array('log')); + $records = $DB->get_records('log'); + + $this->assertEquals(self::DAY, stats_get_start_from('daily'), 'Log entry start'); + + $CFG->statsfirstrun = 'none'; + $this->assertLessThanOrEqual(1, stats_get_start_from('daily') - ($time - (3 * 24 * 3600)), 'None start time'); + + $CFG->statsfirstrun = 14515200; + $this->assertLessThanOrEqual(1, stats_get_start_from('daily') - ($time - (14515200)), 'Specified start time'); + + $this->prepare_db($dataset[1], array('stats_daily')); + $this->assertEquals(self::DAY - 14410 + (24 * 3600), stats_get_start_from('daily'), 'Daily stats start time'); + } + + /** + * Test the function that calculates the start of the day + */ + public function test_statslib_get_base_daily() { + global $CFG; + + $CFG->timezone = 0; + $this->assertEquals(1272672000, stats_get_base_daily(1272686410)); + $CFG->timezone = 5; + $this->assertEquals(1272654000, stats_get_base_daily(1272686410)); + } + + /** + * Test the function that gets the start of the next day + */ + public function test_statslib_get_next_day_start() { + global $CFG; + + $CFG->timezone = 0; + $this->assertEquals(1272758400, stats_get_next_day_start(1272686410)); + } + + /** + * Test the function that gets the action names + * + * Note: The function results depend on installed modules. The hard coded lists are the + * defaults for a new Moodle 2.3 install. + */ + public function test_statslib_get_action_names() { + $basepostactions = array ( + 0 => 'add', + 1 => 'delete', + 2 => 'edit', + 3 => 'add mod', + 4 => 'delete mod', + 5 => 'edit sectionenrol', + 6 => 'loginas', + 7 => 'new', + 8 => 'unenrol', + 9 => 'update', + 10 => 'update mod', + 11 => 'upload', + 12 => 'submit', + 13 => 'submit for grading', + 14 => 'talk', + 15 => 'choose', + 16 => 'choose again', + 17 => 'record delete', + 18 => 'add discussion', + 19 => 'add post', + 20 => 'delete discussion', + 21 => 'delete post', + 22 => 'move discussion', + 23 => 'prune post', + 24 => 'update post', + 25 => 'add category', + 26 => 'add entry', + 27 => 'approve entry', + 28 => 'delete category', + 29 => 'delete entry', + 30 => 'edit category', + 31 => 'update entry', + 32 => 'end', + 33 => 'start', + 34 => 'attempt', + 35 => 'close attempt', + 36 => 'preview', + 37 => 'editquestions', + 38 => 'delete attempt', + 39 => 'manualgrade', + ); + + $baseviewactions = array ( + 0 => 'view', + 1 => 'view all', + 2 => 'history', + 3 => 'view submission', + 4 => 'view feedback', + 5 => 'print', + 6 => 'report', + 7 => 'view discussion', + 8 => 'search', + 9 => 'forum', + 10 => 'forums', + 11 => 'subscribers', + 12 => 'view forum', + 13 => 'view entry', + 14 => 'review', + 15 => 'pre-view', + 16 => 'download', + 17 => 'view form', + 18 => 'view graph', + 19 => 'view report', + ); + + $postactions = stats_get_action_names('post'); + + foreach ($basepostactions as $action) { + $this->assertContains($action, $postactions); + } + + $viewactions = stats_get_action_names('view'); + + foreach ($baseviewactions as $action) { + $this->assertContains($action, $viewactions); + } + } + + /** + * Test the temporary table creation and deletion. + */ + public function test_statslib_temp_table_create_and_drop() { + global $DB; + + foreach ($this->tables as $table) { + $this->assertFalse($DB->get_manager()->table_exists($table)); + } + + stats_temp_table_create(); + + foreach ($this->tables as $table) { + $this->assertTrue($DB->get_manager()->table_exists($table)); + } + + stats_temp_table_drop(); + + foreach ($this->tables as $table) { + $this->assertFalse($DB->get_manager()->table_exists($table)); + } + } + + /** + * Test the temporary table creation and deletion. + * + * @depends test_statslib_temp_table_create_and_drop + */ + public function test_statslib_temp_table_fill() { + global $DB; + + $dataset = $this->load_xml_data_file(__DIR__."/fixtures/statslib-test09.xml"); + + $this->prepare_db($dataset[0], array('log')); + + stats_temp_table_create(); + stats_temp_table_fill(1272686410, 1272758400); + + $this->assertEquals(1, $DB->count_records('temp_log1')); + $this->assertEquals(1, $DB->count_records('temp_log2')); + + stats_temp_table_drop(); + } + + /** + * Test the temporary table creation and deletion. + * + * @depends test_statslib_temp_table_create_and_drop + */ + public function test_statslib_temp_table_setup() { + global $DB; + + $logs = array(); + $this->prepare_db($logs, array('log')); + + stats_temp_table_create(); + stats_temp_table_setup(); + + $this->assertEquals(1, $DB->count_records('temp_enroled')); + + stats_temp_table_drop(); + } + + /** + * Test the function that clean out the temporary tables. + * + * @depends test_statslib_temp_table_create_and_drop + */ + public function test_statslib_temp_table_clean() { + global $DB; + + $rows = array( + 'temp_log1' => array('id' => 1, 'course' => 1), + 'temp_log2' => array('id' => 1, 'course' => 1), + 'temp_stats_daily' => array('id' => 1, 'courseid' => 1), + 'temp_stats_user_daily' => array('id' => 1, 'courseid' => 1), + ); + + stats_temp_table_create(); + + foreach ($rows as $table => $row) { + $DB->insert_record_raw($table, $row); + $this->assertEquals(1, $DB->count_records($table)); + } + + stats_temp_table_clean(); + + foreach ($rows as $table => $row) { + $this->assertEquals(0, $DB->count_records($table)); + } + + $this->assertEquals(1, $DB->count_records('stats_daily')); + $this->assertEquals(1, $DB->count_records('stats_user_daily')); + + stats_temp_table_drop(); + } + + /** + * Test the daily stats function + * + * @depends test_statslib_get_base_daily + * @depends test_statslib_get_next_day_start + * @depends test_statslib_temp_table_create_and_drop + * @depends test_statslib_temp_table_setup + * @depends test_statslib_temp_table_fill + * @dataProvider daily_log_provider + */ + public function test_statslib_cron_daily($logs, $stats) { + global $CFG; + + $CFG->debug = DEBUG_NONE; + + $this->prepare_db($logs, array('log')); + + // Stats cron daily uses mtrace, turn on buffering to silence output. + ob_start(); + stats_cron_daily(1); + ob_end_clean(); + + $this->verify_stats($stats); + } + + /** + * Test the daily stats function + * @depends test_statslib_get_base_daily + * @depends test_statslib_get_next_day_start + */ + public function test_statslib_cron_daily_no_default_profile_id() { + global $CFG, $DB; + $CFG->defaultfrontpageroleid = 0; + + $course1 = $DB->get_record('course', array('shortname' => 'course1')); + $guestid = $CFG->siteguest; + $start = stats_get_base_daily(1272758400); + $end = stats_get_next_day_start($start); + $fpid = (int) $CFG->defaultfrontpageroleid; + $gr = get_guest_role(); + + $dataset = $this->load_xml_data_file(__DIR__."/fixtures/statslib-test10.xml"); + + $CFG->debug = DEBUG_NONE; + + $this->prepare_db($dataset[0], array('log')); + + // Stats cron daily uses mtrace, turn on buffering to silence output. + ob_start(); + stats_cron_daily($maxdays=1); + ob_end_clean(); + + $this->verify_stats($dataset[1]); + } +} From 63e0fe85b5ef93d628c0104e11d9d5387fab6026 Mon Sep 17 00:00:00 2001 From: Tyler Bannister Date: Tue, 4 Sep 2012 10:11:16 -0400 Subject: [PATCH 5/5] RFC-30643 - Added fifth table to speed up enrolment look ups. --- lib/db/install.xml | 20 ++++++- lib/statslib.php | 139 +++++++++++++++++++++++++-------------------- 2 files changed, 96 insertions(+), 63 deletions(-) diff --git a/lib/db/install.xml b/lib/db/install.xml index d1cfa55916f..97d1977aff0 100644 --- a/lib/db/install.xml +++ b/lib/db/install.xml @@ -2882,7 +2882,7 @@ - +
@@ -2897,7 +2897,23 @@
- +
+ + + + + + + + + + + + + + +
+ diff --git a/lib/statslib.php b/lib/statslib.php index eee36ec741f..3d201fd1829 100644 --- a/lib/statslib.php +++ b/lib/statslib.php @@ -103,7 +103,7 @@ function stats_progress($ident) { * @param string $sql The query to run * @return boolean success */ -function stats_run_query($sql, $parameters) { +function stats_run_query($sql, $parameters = array()) { global $DB; try { @@ -190,7 +190,13 @@ function stats_cron_daily($maxdays=1) { $days = 1; $failed = true; } - mtrace("Temporary tables created"); + mtrace('Temporary tables created'); + + if(!stats_temp_table_setup()) { + $days = 1; + $failed = true; + } + mtrace('Enrolments calculated'); $totalactiveusers = $DB->count_records('user', array('deleted' => '0')); @@ -281,15 +287,12 @@ function stats_cron_daily($maxdays=1) { $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'enrolments' AS stattype, $nextmidnight AS timeend, e.courseid, ra.roleid, - COUNT(DISTINCT ue.userid) AS stat1, 0 AS stat2 - FROM {role_assignments} ra - JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) - JOIN {enrol} e ON e.courseid = c.instanceid - JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid) + SELECT 'enrolments' as stattype, $nextmidnight as timeend, courseid, roleid, + COUNT(DISTINCT userid) as stat1, 0 as stat2 + FROM {temp_enroled} GROUP BY courseid, roleid"; - if (!stats_run_query($sql, array('courselevel'=>CONTEXT_COURSE))) { + if (!stats_run_query($sql)) { $failed = true; break; } @@ -300,28 +303,23 @@ function stats_cron_daily($maxdays=1) { $sql = "UPDATE {temp_stats_daily} SET stat2 = ( - SELECT COUNT(DISTINCT ra.userid) - FROM {role_assignments} ra - JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) - JOIN {enrol} e ON e.courseid = c.instanceid - JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid) - WHERE ra.roleid = {temp_stats_daily}.roleid - AND e.courseid = {temp_stats_daily}.courseid + SELECT COUNT(DISTINCT userid) + FROM {temp_enroled} te + WHERE roleid = {temp_stats_daily}.roleid + AND courseid = {temp_stats_daily}.courseid AND EXISTS ( SELECT 'x' FROM {temp_log1} l WHERE l.course = {temp_stats_daily}.courseid - AND l.userid = ra.userid + AND l.userid = te.userid ) - ) + ) + WHERE {temp_stats_daily}.stattype = 'enrolments' + AND {temp_stats_daily}.timeend = $nextmidnight + AND {temp_stats_daily}.courseid IN ( - WHERE {stats_daily}.stattype = 'enrolments' - AND {stats_daily}.timeend = $nextmidnight - AND {stats_daily}.courseid IN ( - - SELECT DISTINCT course FROM {temp_log2} - )"; + SELECT DISTINCT course FROM {temp_log2})"; if ($logspresent && !stats_run_query($sql, array('courselevel'=>CONTEXT_COURSE))) { $failed = true; @@ -332,10 +330,9 @@ function stats_cron_daily($maxdays=1) { // Now get course total enrolments (roleid==0) - except frontpage $sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2) - SELECT 'enrolments', $nextmidnight AS timeend, e.courseid AS courseid, 0 AS roleid, + SELECT 'enrolments', $nextmidnight AS timeend, te.courseid AS courseid, 0 AS roleid, COUNT(DISTINCT userid) AS stat1, 0 AS stat2 - FROM {enrol} e - JOIN {user_enrolments} ue ON ue.enrolid = e.id + FROM {temp_enroled} te GROUP BY courseid HAVING COUNT(DISTINCT userid) > 0"; @@ -349,27 +346,26 @@ function stats_cron_daily($maxdays=1) { $sql = "UPDATE {temp_stats_daily} SET stat2 = ( - SELECT COUNT(DISTINCT ue.userid) - FROM {enrol} e - JOIN {user_enrolments} ue ON ue.enrolid = e.id - WHERE e.courseid = {temp_stats_daily}.courseid - AND EXISTS ( + SELECT COUNT(DISTINCT te.userid) + FROM {temp_enroled} te + WHERE te.courseid = {temp_stats_daily}.courseid + AND EXISTS ( - SELECT 'x' - FROM {temp_log1} l - WHERE l.course = {temp_stats_daily}.courseid - AND l.userid = ue.userid - ) - ) + SELECT 'x' + FROM {temp_log1} l + WHERE l.course = {temp_stats_daily}.courseid + AND l.userid = te.userid + ) + ) WHERE {temp_stats_daily}.stattype = 'enrolments' AND {temp_stats_daily}.timeend = $nextmidnight AND {temp_stats_daily}.roleid = 0 AND {temp_stats_daily}.courseid IN ( - SELECT l.course - FROM {temp_log2} l - WHERE l.course <> ".SITEID.")"; + SELECT l.course + FROM {temp_log2} l + WHERE l.course <> ".SITEID.")"; if ($logspresent && !stats_run_query($sql, array())) { $failed = true; @@ -469,14 +465,12 @@ function stats_cron_daily($maxdays=1) { SELECT pl.courseid, pl.roleid, sud.statsreads, sud.statswrites FROM {temp_stats_user_daily} sud, ( - SELECT DISTINCT ra.userid, ra.roleid, e.courseid - FROM {role_assignments} ra - JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) - JOIN {enrol} e ON e.courseid = c.instanceid - JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid) - WHERE ra.roleid <> $guestrole - AND ra.userid <> $guest - ) pl + SELECT DISTINCT te.userid, te.roleid, te.courseid + FROM {temp_enroled} te + WHERE te.roleid <> $guestrole + AND te.userid <> $guest + ) pl + WHERE sud.userid = pl.userid AND sud.courseid = pl.courseid AND sud.timeend = $nextmidnight @@ -508,10 +502,9 @@ function stats_cron_daily($maxdays=1) { AND sud.stattype='activity' AND (sud.userid = $guest OR sud.userid NOT IN ( - SELECT ue.userid - FROM {user_enrolments} ue - JOIN {enrol} e ON ue.enrolid = e.id - WHERE e.courseid = sud.courseid + SELECT userid + FROM {temp_enroled} te + WHERE te.courseid = sud.courseid )) ) inline_view @@ -1444,7 +1437,7 @@ function stats_get_report_options($courseid,$mode) { $reportoptions[STATS_REPORT_PARTICIPATORY_COURSES] = get_string('statsreport'.STATS_REPORT_PARTICIPATORY_COURSES); $reportoptions[STATS_REPORT_PARTICIPATORY_COURSES_RW] = get_string('statsreport'.STATS_REPORT_PARTICIPATORY_COURSES_RW); } - break; + break; } return $reportoptions; @@ -1562,9 +1555,10 @@ function stats_temp_table_create() { // Allows for the additional xml files to be used (if necessary) $files = array( $xmlfile => array( - 'stats_daily' => array('temp_stats_daily'), - 'stats_user_daily' => array('temp_stats_user_daily'), - 'temp_log_template' => array('temp_log1', 'temp_log2'), + 'stats_daily' => array('temp_stats_daily'), + 'stats_user_daily' => array('temp_stats_user_daily'), + 'temp_enroled_template' => array('temp_enroled'), + 'temp_log_template' => array('temp_log1', 'temp_log2'), ), ); @@ -1619,7 +1613,7 @@ function stats_temp_table_drop() { $dbman = $DB->get_manager(); - $tables = array('temp_log1', 'temp_log2', 'temp_stats_daily', 'temp_stats_user_daily'); + $tables = array('temp_log1', 'temp_log2', 'temp_stats_daily', 'temp_stats_user_daily', 'temp_enroled'); foreach ($tables as $name) { @@ -1638,6 +1632,31 @@ function stats_temp_table_drop() { /** * Fills the temporary stats tables with new data * + * This function is meant to be called once at the start of stats generation + * + * @param timestart timestamp of the start time of logs view + * @param timeend timestamp of the end time of logs view + * @returns boolen success (true) or failure(false) + */ +function stats_temp_table_setup() { + global $DB; + + $sql = "INSERT INTO {temp_enroled} (userid, courseid, roleid) + + SELECT ue.userid, e.courseid, ra.roleid + FROM {role_assignments} ra + JOIN {context} c ON (c.id = ra.contextid AND c.contextlevel = :courselevel) + JOIN {enrol} e ON e.courseid = c.instanceid + JOIN {user_enrolments} ue ON (ue.enrolid = e.id AND ue.userid = ra.userid)"; + + return stats_run_query($sql, array('courselevel' => CONTEXT_COURSE)); +} + +/** + * Fills the temporary stats tables with new data + * + * This function is meant to be called to get a new day of data + * * @param timestart timestamp of the start time of logs view * @param timeend timestamp of the end time of logs view * @returns boolen success (true) or failure(false) @@ -1683,9 +1702,7 @@ function stats_temp_table_clean() { FROM {temp_stats_user_daily}'; foreach ($sql as $id => $query) { - try { - $DB->execute($query); - } catch (Exception $e) { + if (! stats_run_query($query)) { mtrace("Error during table cleanup!"); return false; }