Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP
Browse files

MDL-20946 fix gradebook SQL to cope with multi-role and deleted users.

  • Loading branch information...
commit 6d276b3254cbe2dc1d041dc08712e83829334ab5 1 parent 08bf2b2
@timhunt timhunt authored
Showing with 61 additions and 51 deletions.
  1. +17 −9 grade/lib.php
  2. +44 −42 grade/report/grader/lib.php
View
26 grade/lib.php
@@ -108,10 +108,14 @@ function init() {
$users_sql = "SELECT u.* $ofields
FROM {$CFG->prefix}user u
- INNER JOIN {$CFG->prefix}role_assignments ra ON u.id = ra.userid
$groupsql
- WHERE ra.roleid $gradebookroles
- AND ra.contextid $relatedcontexts
+ WHERE u.id IN (
+ SELECT DISTINCT ra.userid
+ FROM {$CFG->prefix}role_assignments ra
+ WHERE ra.roleid $gradebookroles
+ AND ra.contextid $relatedcontexts
+ )
+ AND u.deleted = 0
$groupwheresql
ORDER BY $order";
@@ -123,13 +127,17 @@ function init() {
$grades_sql = "SELECT g.* $ofields
FROM {$CFG->prefix}grade_grades g
- INNER JOIN {$CFG->prefix}user u ON g.userid = u.id
- INNER JOIN {$CFG->prefix}role_assignments ra ON u.id = ra.userid
+ JOIN {$CFG->prefix}user u ON g.userid = u.id
$groupsql
- WHERE ra.roleid $gradebookroles
- AND ra.contextid $relatedcontexts
- AND g.itemid IN ($itemids)
- $groupwheresql
+ WHERE u.id IN (
+ SELECT DISTINCT ra.userid
+ FROM {$CFG->prefix}role_assignments ra
+ WHERE ra.roleid $gradebookroles
+ AND ra.contextid $relatedcontexts
+ )
+ AND u.deleted = 0
+ AND g.itemid IN ($itemids)
+ $groupwheresql
ORDER BY $order, g.itemid ASC";
$this->grades_rs = get_recordset_sql($grades_sql);
} else {
View
86 grade/report/grader/lib.php
@@ -327,41 +327,38 @@ function load_users() {
global $CFG;
if (is_numeric($this->sortitemid)) {
- // the MAX() magic is required in order to please PG
- $sort = "MAX(g.finalgrade) $this->sortorder";
-
- $sql = "SELECT u.id, u.firstname, u.lastname, u.imagealt, u.picture, u.idnumber
- FROM {$CFG->prefix}user u
- JOIN {$CFG->prefix}role_assignments ra ON ra.userid = u.id
- $this->groupsql
- LEFT JOIN {$CFG->prefix}grade_grades g ON (g.userid = u.id AND g.itemid = $this->sortitemid)
- WHERE ra.roleid in ($this->gradebookroles) AND u.deleted = 0
- $this->groupwheresql
- AND ra.contextid ".get_related_contexts_string($this->context)."
- GROUP BY u.id, u.firstname, u.lastname, u.imagealt, u.picture, u.idnumber
- ORDER BY $sort";
-
+ $sortjoin = "LEFT JOIN {$CFG->prefix}grade_grades g ON " .
+ "g.userid = u.id AND g.itemid = $this->sortitemid";
+ $sort = "g.finalgrade $this->sortorder";
} else {
+ $sortjoin = '';
switch($this->sortitemid) {
case 'lastname':
- $sort = "u.lastname $this->sortorder, u.firstname $this->sortorder"; break;
+ $sort = "u.lastname $this->sortorder, u.firstname $this->sortorder";
+ break;
case 'firstname':
- $sort = "u.firstname $this->sortorder, u.lastname $this->sortorder"; break;
+ $sort = "u.firstname $this->sortorder, u.lastname $this->sortorder";
+ break;
case 'idnumber':
default:
- $sort = "u.idnumber $this->sortorder"; break;
+ $sort = "u.idnumber $this->sortorder";
+ break;
}
-
- $sql = "SELECT DISTINCT u.id, u.firstname, u.lastname, u.imagealt, u.picture, u.idnumber
- FROM {$CFG->prefix}user u
- JOIN {$CFG->prefix}role_assignments ra ON u.id = ra.userid
- $this->groupsql
- WHERE ra.roleid in ($this->gradebookroles)
- $this->groupwheresql
- AND ra.contextid ".get_related_contexts_string($this->context)."
- ORDER BY $sort";
}
+ $sql = "SELECT u.id, u.firstname, u.lastname, u.imagealt, u.picture, u.idnumber
+ FROM {$CFG->prefix}user u
+ $this->groupsql
+ $sortjoin
+ WHERE u.id IN (
+ SELECT DISTINCT ra.userid
+ FROM {$CFG->prefix}role_assignments ra
+ WHERE ra.roleid IN ($this->gradebookroles)
+ AND ra.contextid " . get_related_contexts_string($this->context) . "
+ )
+ AND u.deleted = 0
+ $this->groupwheresql
+ ORDER BY $sort";
$this->users = get_records_sql($sql, $this->get_pref('studentsperpage') * $this->page,
$this->get_pref('studentsperpage'));
@@ -1152,20 +1149,24 @@ function get_avghtml($grouponly=false) {
if ($showaverages) {
// find sums of all grade items in course
- $SQL = "SELECT g.itemid, SUM(g.finalgrade) AS sum
+ $sql = "SELECT g.itemid, SUM(g.finalgrade) AS sum
FROM {$CFG->prefix}grade_items gi
- JOIN {$CFG->prefix}grade_grades g ON g.itemid = gi.id
- JOIN {$CFG->prefix}user u ON u.id = g.userid
- JOIN {$CFG->prefix}role_assignments ra ON ra.userid = u.id
+ JOIN {$CFG->prefix}grade_grades g ON g.itemid = gi.id
+ JOIN {$CFG->prefix}user u ON u.id = g.userid
$groupsql
- WHERE gi.courseid = $this->courseid
- AND ra.roleid in ($this->gradebookroles)
- AND ra.contextid ".get_related_contexts_string($this->context)."
- AND g.finalgrade IS NOT NULL
- $groupwheresql
+ WHERE gi.courseid = $this->courseid
+ AND u.id IN (
+ SELECT DISTINCT ra.userid
+ FROM {$CFG->prefix}role_assignments ra
+ WHERE ra.roleid IN ($this->gradebookroles)
+ AND ra.contextid " . get_related_contexts_string($this->context) . "
+ )
+ AND u.deleted = 0
+ AND g.finalgrade IS NOT NULL
+ $groupwheresql
GROUP BY g.itemid";
$sum_array = array();
- if ($sums = get_records_sql($SQL)) {
+ if ($sums = get_records_sql($sql)) {
foreach ($sums as $itemid => $csum) {
$sum_array[$itemid] = $csum->sum;
}
@@ -1177,20 +1178,21 @@ function get_avghtml($grouponly=false) {
// MDL-10875 Empty grades must be evaluated as grademin, NOT always 0
// This query returns a count of ungraded grades (NULL finalgrade OR no matching record in grade_grades table)
- $SQL = "SELECT gi.id, COUNT(u.id) AS count
+ $sql = "SELECT gi.id, COUNT(DISTINCT u.id) AS count
FROM {$CFG->prefix}grade_items gi
CROSS JOIN {$CFG->prefix}user u
- JOIN {$CFG->prefix}role_assignments ra ON ra.userid = u.id
- LEFT OUTER JOIN {$CFG->prefix}grade_grades g ON (g.itemid = gi.id AND g.userid = u.id AND g.finalgrade IS NOT NULL)
+ JOIN {$CFG->prefix}role_assignments ra ON ra.userid = u.id
+ LEFT OUTER JOIN {$CFG->prefix}grade_grades g ON g.itemid = gi.id AND g.userid = u.id AND g.finalgrade IS NOT NULL
$groupsql
WHERE gi.courseid = $this->courseid
- AND ra.roleid in ($this->gradebookroles)
- AND ra.contextid ".get_related_contexts_string($this->context)."
+ AND ra.roleid IN ($this->gradebookroles)
+ AND u.deleted = 0
+ AND ra.contextid " . get_related_contexts_string($this->context) . "
AND g.id IS NULL
$groupwheresql
GROUP BY gi.id";
- $ungraded_counts = get_records_sql($SQL);
+ $ungraded_counts = get_records_sql($sql);
$fixedstudents = $this->is_fixed_students();
if (!$fixedstudents) {
Please sign in to comment.
Something went wrong with that request. Please try again.