Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Added compatibility for T-SQL (which is SQL Server's syntax) #11

Open
wants to merge 1 commit into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
12 changes: 9 additions & 3 deletions reports/activities/classes/query_helper.php
Original file line number Diff line number Diff line change
Expand Up @@ -68,15 +68,21 @@ public static function query_activities(int $courseid, string $filter = '', arra
}

public static function preview_query_most_clicked_activity(int $courseid, $privacythreshold) {
global $DB;
global $CFG, $DB;

$date = new \DateTime();
$date->setTime(23, 59, 59); // Include today.
$date->modify('-1 week');
$oneweekago = $date->getTimestamp();

# Handling of max rows to be returned
if ($CFG->dbtype === 'sqlsrv')
$top = 'TOP 3';
else
$limit = 'LIMIT 3';

$query = <<<SQL
SELECT
SELECT {$top}
cm.id AS cmid,
m.name as modname,
COUNT(*) AS hits
Expand All @@ -94,7 +100,7 @@ public static function preview_query_most_clicked_activity(int $courseid, $priva
GROUP BY cm.id, m.name
HAVING count(*) >= ?
ORDER BY hits DESC
LIMIT 3
{$limit}
SQL;

return $DB->get_records_sql($query, [$courseid, $oneweekago, max(1, $privacythreshold)]);
Expand Down
13 changes: 10 additions & 3 deletions reports/coursedashboard/classes/query_helper.php
Original file line number Diff line number Diff line change
Expand Up @@ -29,7 +29,7 @@
class query_helper {

public static function query_weekly_activity(int $courseid) : array {
global $DB;
global $CFG, $DB;

$course = get_course($courseid);

Expand All @@ -38,14 +38,21 @@ public static function query_weekly_activity(int $courseid) : array {
$startdate->modify('Monday this week'); // Get start of week.

$mondaytimestamp = $startdate->format('U');
$week = "(FLOOR((l.timecreated - {$mondaytimestamp}) / (7 * 60 * 60 * 24)) + 1)";

# T-SQL (which is SQL Server's syntax) cannot GROUP BY column aliases
if ($CFG->dbtype === 'sqlsrv')
$group_by = $week;
else
$group_by = 'week';

$query = <<<SQL
SELECT (FLOOR((l.timecreated - {$mondaytimestamp}) / (7 * 60 * 60 * 24)) + 1)
SELECT {$week}
AS WEEK,
COUNT(*) clicks
FROM {logstore_lanalytics_log} l
WHERE l.courseid = ?
GROUP BY week
GROUP BY {$group_by}
ORDER BY week;
SQL;

Expand Down
21 changes: 17 additions & 4 deletions reports/learners/classes/query_helper.php
Original file line number Diff line number Diff line change
Expand Up @@ -83,6 +83,12 @@ public static function query_courseparticipation(

$pgspecialcase = ($CFG->dbtype === 'pgsql') ? '' : ', co.startdate';

# T-SQL (which is SQL Server's syntax) must have all selected columns contained in the GROUP BY clause
if ($CFG->dbtype === 'sqlsrv')
$group_by = "co.{$groupbychoice}, {$coursename}, {$casevalue}, co.startdate";
else
$group_by = "co.{$groupbychoice}, {$casevalue}";

$query = <<<SQL
SELECT
{$selectconcat} AS uniqueval,-- first row needs to be unique for moodle...
Expand Down Expand Up @@ -116,7 +122,7 @@ public static function query_courseparticipation(
AND e.courseid = ?
AND co.startdate <> 0
AND co.visible = 1
GROUP BY co.{$groupbychoice}, {$casevalue}
GROUP BY {$group_by}
HAVING COUNT(*) > ? AND {$casevalue} <> 0
ORDER BY users DESC;
SQL;
Expand Down Expand Up @@ -160,16 +166,23 @@ public static function query_localization(int $courseid, string $type) : array {
// Returns array like [100, 50] meaning 100 students were already registered since last week
// and 50 more students join in the last days.
public static function preview_query_users(int $courseid) : array {
global $DB;
global $CFG, $DB;

$date = new \DateTime();
$date->modify('-1 week');

$timestamp = $date->getTimestamp();
$case = "CASE WHEN ue.timestart < {$timestamp} THEN 0 ELSE 1 END";

# T-SQL (which is SQL Server's syntax) cannot GROUP BY column aliases
if ($CFG->dbtype === 'sqlsrv')
$group_by = $case;
else
$group_by = 'time';

$query = <<<SQL
SELECT
CASE WHEN ue.timestart < {$timestamp} THEN 0 ELSE 1 END AS time,
{$case} AS time,
COUNT(DISTINCT u.id) AS learners
FROM {user} u
JOIN {user_enrolments} ue
Expand All @@ -178,7 +191,7 @@ public static function preview_query_users(int $courseid) : array {
ON e.id = ue.enrolid
WHERE u.deleted = 0
AND e.courseid = ?
GROUP BY time
GROUP BY {$group_by}
ORDER BY time;
SQL;

Expand Down
10 changes: 8 additions & 2 deletions reports/quiz_assign/classes/query_helper.php
Original file line number Diff line number Diff line change
Expand Up @@ -34,7 +34,13 @@
class query_helper {

public static function query_quiz(int $courseid): array {
global $DB;
global $CFG, $DB;

# T-SQL (which is SQL Server's syntax) must have all selected columns contained in the GROUP BY clause
if ($CFG->dbtype === 'sqlsrv')
$group_by = 'q.id, q.sumgrades';
else
$group_by = 'q.id';

$query = <<<SQL
SELECT
Expand All @@ -55,7 +61,7 @@ public static function query_quiz(int $courseid): array {
WHERE gi.courseid = ?
AND gi.itemtype = 'mod'
AND gi.itemmodule = 'quiz'
GROUP BY q.id
GROUP BY {$group_by}
SQL;

return $DB->get_records_sql($query, [$courseid]);
Expand Down
7 changes: 6 additions & 1 deletion reports/weekheatmap/classes/query_helper.php
Original file line number Diff line number Diff line change
Expand Up @@ -38,11 +38,16 @@ public static function query_heatmap(int $courseid): array {
global $DB, $CFG;

$weekstatement = "FROM_UNIXTIME(l.timecreated, '%w-%k')";
$group_by = 'heatpoint';

if ($CFG->dbtype === 'pgsql') {
$date = new DateTime();
$timezone = $date->getTimezone()->getName();
$weekstatement = "TO_CHAR(TO_TIMESTAMP(l.timecreated) at time zone '".$timezone."', 'D-HH24')";
} elseif ($CFG->dbtype === 'sqlsrv') {
# T-SQL (which is SQL Server's syntax) cannot GROUP BY column aliases
$weekstatement = "CONCAT(DATEPART(weekday, DATEADD(SECOND, l.timecreated, '1970-01-01')) - 1, '-', DATEPART(hour, DATEADD(SECOND, l.timecreated + 3600, '1970-01-01')))";
$group_by = $weekstatement;
}

// MySQL returns points where 0-00 => Sun,0-1am; 0-01 => Sun,1-2am; ...
Expand All @@ -53,7 +58,7 @@ public static function query_heatmap(int $courseid): array {
COUNT(1) AS value
FROM {logstore_lanalytics_log} AS l
WHERE l.courseid = ?
GROUP BY heatpoint
GROUP BY {$group_by}
ORDER BY heatpoint
SQL;

Expand Down