mirror of
https://github.com/moodle/moodle.git
synced 2025-04-21 00:12:56 +02:00
Merge branch 'MDL-30643_master-log-speed' of git://github.com/tbannister/moodle
This commit is contained in:
commit
b0381539e5
57
lib/db/temp_stats_log_template.xml
Normal file
57
lib/db/temp_stats_log_template.xml
Normal file
@ -0,0 +1,57 @@
|
||||
<?xml version="1.0" encoding="UTF-8" ?>
|
||||
<XMLDB PATH="lib/db" VERSION="20120631" COMMENT="XMLDB file for statistics temporary log tables"
|
||||
xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
|
||||
xsi:noNamespaceSchemaLocation="../../lib/xmldb/xmldb.xsd">
|
||||
<TABLES>
|
||||
<TABLE NAME="temp_log1" COMMENT="Temporary storage for daily logs" NEXT="temp_log2">
|
||||
<FIELDS>
|
||||
<FIELD NAME="id" TYPE="int" LENGTH="10" NOTNULL="true" SEQUENCE="true" NEXT="userid"/>
|
||||
<FIELD NAME="userid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" PREVIOUS="id" NEXT="course"/>
|
||||
<FIELD NAME="course" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" PREVIOUS="userid" NEXT="action"/>
|
||||
<FIELD NAME="action" TYPE="char" LENGTH="40" NOTNULL="true" SEQUENCE="false" PREVIOUS="course"/>
|
||||
</FIELDS>
|
||||
<KEYS>
|
||||
<KEY NAME="primary" TYPE="primary" FIELDS="id"/>
|
||||
</KEYS>
|
||||
<INDEXES>
|
||||
<INDEX NAME="action" UNIQUE="false" FIELDS="action" NEXT="course"/>
|
||||
<INDEX NAME="course" UNIQUE="false" FIELDS="course" PREVIOUS="action" NEXT="user"/>
|
||||
<INDEX NAME="user" UNIQUE="false" FIELDS="userid" PREVIOUS="course" NEXT="usercourseaction"/>
|
||||
<INDEX NAME="usercourseaction" UNIQUE="false" FIELDS="userid, course, action" PREVIOUS="user"/>
|
||||
</INDEXES>
|
||||
</TABLE>
|
||||
<TABLE NAME="temp_log2" COMMENT="Duplicate temporary storage for daily logs (work around for MySQL issue)" PREVIOUS="temp_log1" NEXT="temp_enroled">
|
||||
<FIELDS>
|
||||
<FIELD NAME="id" TYPE="int" LENGTH="10" NOTNULL="true" SEQUENCE="true" NEXT="userid"/>
|
||||
<FIELD NAME="userid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" PREVIOUS="id" NEXT="course"/>
|
||||
<FIELD NAME="course" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" PREVIOUS="userid" NEXT="action"/>
|
||||
<FIELD NAME="action" TYPE="char" LENGTH="40" NOTNULL="true" SEQUENCE="false" PREVIOUS="course"/>
|
||||
</FIELDS>
|
||||
<KEYS>
|
||||
<KEY NAME="primary" TYPE="primary" FIELDS="id"/>
|
||||
</KEYS>
|
||||
<INDEXES>
|
||||
<INDEX NAME="action" UNIQUE="false" FIELDS="action" NEXT="course"/>
|
||||
<INDEX NAME="course" UNIQUE="false" FIELDS="course" PREVIOUS="action" NEXT="user"/>
|
||||
<INDEX NAME="user" UNIQUE="false" FIELDS="userid" PREVIOUS="course" NEXT="usercourseaction"/>
|
||||
<INDEX NAME="usercourseaction" UNIQUE="false" FIELDS="userid, course, action" PREVIOUS="user"/>
|
||||
</INDEXES>
|
||||
</TABLE>
|
||||
<TABLE NAME="temp_enroled" COMMENT="Temporary storage for course enrolments" PREVIOUS="temp_log2">
|
||||
<FIELDS>
|
||||
<FIELD NAME="id" TYPE="int" LENGTH="10" NOTNULL="true" SEQUENCE="true" NEXT="userid"/>
|
||||
<FIELD NAME="userid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" PREVIOUS="id" NEXT="courseid"/>
|
||||
<FIELD NAME="courseid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" PREVIOUS="userid" NEXT="roleid"/>
|
||||
<FIELD NAME="roleid" TYPE="char" LENGTH="40" NOTNULL="true" SEQUENCE="false" PREVIOUS="courseid"/>
|
||||
</FIELDS>
|
||||
<KEYS>
|
||||
<KEY NAME="primary" TYPE="primary" FIELDS="id"/>
|
||||
</KEYS>
|
||||
<INDEXES>
|
||||
<INDEX NAME="userid" UNIQUE="false" FIELDS="userid" NEXT="courseid"/>
|
||||
<INDEX NAME="courseid" UNIQUE="false" FIELDS="courseid" PREVIOUS="userid" NEXT="roleid"/>
|
||||
<INDEX NAME="roleid" UNIQUE="false" FIELDS="roleid" PREVIOUS="courseid"/>
|
||||
</INDEXES>
|
||||
</TABLE>
|
||||
</TABLES>
|
||||
</XMLDB>
|
589
lib/statslib.php
589
lib/statslib.php
@ -75,17 +75,17 @@ define('STATS_MODE_RANKED',3); // admins only - ranks courses
|
||||
* 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 ", '');
|
||||
@ -156,14 +156,27 @@ 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');
|
||||
|
||||
if(!stats_temp_table_setup()) {
|
||||
$days = 1;
|
||||
$failed = true;
|
||||
}
|
||||
mtrace('Enrolments caclulated');
|
||||
|
||||
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 +189,52 @@ 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');
|
||||
if (!stats_temp_table_fill($timestart, $nextmidnight)) {
|
||||
$failed = true;
|
||||
break;
|
||||
}
|
||||
|
||||
|
||||
/// find out if any logs available for this day
|
||||
$sql = "SELECT 'x'
|
||||
FROM {log} l
|
||||
WHERE $timesql";
|
||||
/// 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);
|
||||
|
||||
/// process login info first
|
||||
$sql = "INSERT INTO {stats_user_daily} (stattype, timeend, courseid, userid, statsreads)
|
||||
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_raw('temp_log1', array('userid' => 0, 'course' => SITEID, 'action' => ''));
|
||||
}
|
||||
|
||||
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
|
||||
stats_progress('0');
|
||||
|
||||
/// process login info first
|
||||
$sql = "INSERT INTO {temp_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(statsreads) > 0";
|
||||
|
||||
if ($logspresent and !$DB->execute($sql)) {
|
||||
$failed = true;
|
||||
break;
|
||||
}
|
||||
stats_daily_progress('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((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();
|
||||
COALESCE(SUM(statsreads), 0) as stat1, COUNT('x') as stat2
|
||||
FROM {temp_stats_user_daily}
|
||||
WHERE stattype = 'logins' AND timeend = $nextmidnight";
|
||||
|
||||
if ($logspresent and !$DB->execute($sql)) {
|
||||
$failed = true;
|
||||
break;
|
||||
}
|
||||
stats_daily_progress('2');
|
||||
stats_progress('2');
|
||||
|
||||
|
||||
// Enrolments and active enrolled users
|
||||
@ -235,93 +247,82 @@ 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', 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, courseid, roleid,
|
||||
COUNT(DISTINCT userid) as stat1, 0 as stat2
|
||||
FROM {temp_enroled}
|
||||
GROUP BY courseid, roleid";
|
||||
|
||||
if (!$DB->execute($sql, array('courselevel'=>CONTEXT_COURSE))) {
|
||||
if (!$DB->execute($sql)) {
|
||||
$failed = true;
|
||||
break;
|
||||
}
|
||||
stats_daily_progress('3');
|
||||
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 {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)";
|
||||
$sql = "UPDATE {temp_stats_daily}
|
||||
SET stat2 = (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 = te.userid))
|
||||
WHERE {temp_stats_daily}.stattype = 'enrolments' AND
|
||||
{temp_stats_daily}.timeend = $nextmidnight AND
|
||||
{temp_stats_daily}.courseid IN
|
||||
(SELECT DISTINCT course
|
||||
FROM {temp_log2})";
|
||||
|
||||
if (!$DB->execute($sql, array('courselevel'=>CONTEXT_COURSE))) {
|
||||
if ($logspresent and !$DB->execute($sql, array('courselevel'=>CONTEXT_COURSE))) {
|
||||
$failed = true;
|
||||
break;
|
||||
}
|
||||
stats_daily_progress('4');
|
||||
stats_progress('4');
|
||||
|
||||
/// now get course total enrolments (roleid==0) - except frontpage
|
||||
$sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2)
|
||||
/// now get course total enrolments (roleid==0) - except frontpage
|
||||
$sql = "INSERT INTO {temp_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, te.courseid AS courseid, 0 AS roleid,
|
||||
COUNT(DISTINCT userid) AS stat1, 0 AS stat2
|
||||
FROM {temp_enroled} te
|
||||
GROUP BY courseid
|
||||
HAVING COUNT(DISTINCT userid) > 0";
|
||||
|
||||
if ($logspresent and !$DB->execute($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
|
||||
// Set stat 2 to the number of enrolled users who were active in the course
|
||||
$sql = "UPDATE {temp_stats_daily}
|
||||
SET stat2 = (SELECT COUNT(DISTINCT te.userid)
|
||||
FROM {temp_enroled} te
|
||||
WHERE te.courseid = {temp_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
|
||||
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 {log} l
|
||||
WHERE $timesql AND l.course <> ".SITEID.")";
|
||||
FROM {temp_log2} l
|
||||
WHERE l.course <> ".SITEID.")";
|
||||
|
||||
if ($logspresent and !$DB->execute($sql, array())) {
|
||||
$failed = true;
|
||||
break;
|
||||
}
|
||||
stats_daily_progress('6');
|
||||
stats_progress('6');
|
||||
|
||||
/// frontapge(==site) enrolments total
|
||||
$sql = "INSERT INTO {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2)
|
||||
/// frontpage(==site) enrolments total
|
||||
$sql = "INSERT INTO {temp_stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2)
|
||||
|
||||
SELECT 'enrolments', $nextmidnight, ".SITEID.", 0,
|
||||
(SELECT COUNT('x')
|
||||
@ -329,30 +330,30 @@ function stats_cron_daily($maxdays=1) {
|
||||
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" .
|
||||
JOIN {temp_log1} l ON l.userid = u.id
|
||||
WHERE u.deleted = 0) AS stat2" .
|
||||
$DB->sql_null_from_clause();
|
||||
|
||||
if ($logspresent and !$DB->execute($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}
|
||||
FROM {temp_stats_daily}
|
||||
WHERE stattype = 'enrolments' AND courseid = ".SITEID." AND
|
||||
roleid = $defaultfproleid AND timeend = $nextmidnight";
|
||||
if ($logspresent and !$DB->execute($sql)) {
|
||||
$failed = true;
|
||||
break;
|
||||
}
|
||||
stats_daily_progress('8');
|
||||
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,
|
||||
(SELECT COUNT('x')
|
||||
@ -360,92 +361,69 @@ function stats_cron_daily($maxdays=1) {
|
||||
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" .
|
||||
JOIN {temp_log1} l ON l.userid = u.id
|
||||
WHERE u.deleted = 0) AS stat2" .
|
||||
$DB->sql_null_from_clause();;
|
||||
|
||||
if ($logspresent and !$DB->execute($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
|
||||
/// 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, 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
|
||||
GROUP BY userid, courseid";
|
||||
|
||||
if ($logspresent and !$DB->execute($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)
|
||||
/// 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,
|
||||
(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))) {
|
||||
$failed = true;
|
||||
break;
|
||||
}
|
||||
stats_daily_progress('11');
|
||||
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 {stats_daily} (stattype, timeend, courseid, roleid, stat1, stat2)
|
||||
$sql = "INSERT INTO {temp_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
|
||||
SELECT pl.courseid, pl.roleid, sud.statsreads, sud.statswrites
|
||||
FROM {temp_stats_user_daily} sud,
|
||||
(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
|
||||
@ -459,42 +437,43 @@ function stats_cron_daily($maxdays=1) {
|
||||
$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
|
||||
/// 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', 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
|
||||
SELECT sud.courseid, sud.statsreads, sud.statswrites
|
||||
FROM {temp_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))
|
||||
NOT IN (SELECT userid
|
||||
FROM {temp_enroled} te
|
||||
WHERE te.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())) {
|
||||
$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)
|
||||
/// 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', 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 pl.courseid, pl.roleid, sud.statsreads, sud.statswrites
|
||||
FROM {temp_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
|
||||
@ -515,16 +494,17 @@ function stats_cron_daily($maxdays=1) {
|
||||
$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)
|
||||
/// 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, 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
|
||||
SELECT sud.timeend AS timeend, sud.courseid, sud.statsreads, sud.statswrites
|
||||
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 AND sud.userid
|
||||
@ -533,55 +513,68 @@ function stats_cron_daily($maxdays=1) {
|
||||
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))) {
|
||||
$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)
|
||||
/// 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', 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
|
||||
SELECT pl.statsreads, pl.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." AND
|
||||
sud.stattype='activity'
|
||||
) pl
|
||||
) 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)) {
|
||||
$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) {
|
||||
$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 ({$total} s) - 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 +627,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)
|
||||
|
||||
@ -648,6 +644,8 @@ function stats_cron_weekly() {
|
||||
|
||||
$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 +659,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 +674,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 +689,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 +704,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 +769,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 +785,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 +800,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 +815,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 +830,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 +845,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);
|
||||
@ -1332,7 +1347,7 @@ function stats_get_report_options($courseid,$mode) {
|
||||
switch ($mode) {
|
||||
case STATS_MODE_GENERAL:
|
||||
$reportoptions[STATS_REPORT_ACTIVITY] = get_string('statsreport'.STATS_REPORT_ACTIVITY);
|
||||
if ($courseid != SITEID && $context = context_course::instance($courseid)) {
|
||||
if ($courseid != SITEID && $context = context_course::instance(CONTEXT_COURSE, $courseid)) {
|
||||
$sql = 'SELECT r.id, r.name FROM {role} r JOIN {stats_daily} s ON s.roleid = r.id WHERE s.courseid = :courseid GROUP BY r.id, r.name';
|
||||
if ($roles = $DB->get_records_sql($sql, array('courseid' => $courseid))) {
|
||||
foreach ($roles as $role) {
|
||||
@ -1362,7 +1377,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;
|
||||
@ -1462,3 +1477,183 @@ 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();
|
||||
|
||||
$xmlfile = $CFG->dirroot . '/lib/db/install.xml';
|
||||
$tempfile = $CFG->dirroot . '/lib/db/temp_stats_log_template.xml';
|
||||
$tables = array();
|
||||
$files = array(
|
||||
$xmlfile => array('stats_daily', 'stats_user_daily'),
|
||||
$tempfile => array('temp_log1', 'temp_log2', 'temp_enroled'),
|
||||
);
|
||||
|
||||
foreach ($files as $file => $contents) {
|
||||
|
||||
$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();
|
||||
|
||||
foreach ($contents as $name) {
|
||||
$table = $xmldb_structure->getTable($name);
|
||||
|
||||
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);
|
||||
$tables[$name] = $table;
|
||||
}
|
||||
}
|
||||
|
||||
// Rename the standard table templates so that they don't conflict with the standard tables
|
||||
$tables['stats_daily']->setName('temp_stats_daily');
|
||||
$tables['stats_user_daily']->setName('temp_stats_user_daily');
|
||||
|
||||
try {
|
||||
|
||||
foreach ($tables as $table) {
|
||||
$dbman->create_temp_table($table);
|
||||
}
|
||||
|
||||
} catch (Exception $e) {
|
||||
mtrace('Temporary table creation failed: '. $e->getMessage());
|
||||
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', 'temp_stats_daily', 'temp_stats_user_daily', 'temp_enroled');
|
||||
|
||||
foreach ($tables as $name) {
|
||||
|
||||
if ($dbman->table_exists($name)) {
|
||||
$table = new xmldb_table($name);
|
||||
|
||||
try {
|
||||
$dbman->drop_table($table);
|
||||
} catch (Exception $e) {
|
||||
mtrace("Error occured while dropping temporary tables!");
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
/**
|
||||
* 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)";
|
||||
|
||||
if (!$DB->execute($sql, array('courselevel' => CONTEXT_COURSE))) {
|
||||
return false;
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
/**
|
||||
* 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)
|
||||
*/
|
||||
function stats_temp_table_fill($timestart, $timeend) {
|
||||
global $DB;
|
||||
|
||||
$sql = "INSERT INTO {temp_log1}
|
||||
SELECT id, userid, course, action FROM {log} l
|
||||
WHERE l.time >= $timestart AND l.time < $timeend";
|
||||
|
||||
if (!$DB->execute($sql)) {
|
||||
return false;
|
||||
}
|
||||
|
||||
$sql = "INSERT INTO {temp_log2}
|
||||
SELECT * FROM {temp_log1}";
|
||||
|
||||
if (!$DB->execute($sql)) {
|
||||
return false;
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
|
||||
/**
|
||||
* Deletes summary logs table for stats calculation
|
||||
*
|
||||
* @returns boolen success (true) or failure(false)
|
||||
*/
|
||||
function stats_temp_table_clean() {
|
||||
global $DB;
|
||||
|
||||
$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}';
|
||||
|
||||
$x = 1;
|
||||
$tables = array('temp_log1', 'temp_log2', 'temp_stats_daily', 'temp_stats_user_daily');
|
||||
|
||||
foreach ($tables as $name) {
|
||||
$sql['tr'. $x] = "TRUNCATE TABLE {{$name}}";
|
||||
$x += 1;
|
||||
}
|
||||
|
||||
foreach ($sql as $id => $query) {
|
||||
try {
|
||||
$DB->execute($query);
|
||||
} catch (Exception $e) {
|
||||
mtrace("Error during table cleanup!");
|
||||
return false;
|
||||
}
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
1554
lib/tests/statslib_test.php
Normal file
1554
lib/tests/statslib_test.php
Normal file
File diff suppressed because it is too large
Load Diff
Loading…
x
Reference in New Issue
Block a user