Skip to content

Commit

Permalink
MDL-44725 Availability: Add SQL feature for user lists (11)
Browse files Browse the repository at this point in the history
The previous API included a facility to filter a list of users
to include only those who are allowed to access an activity, i.e.
only people who belong to the required groups etc.

This change adds a new API function to return SQL that obtains
this list of users, so that it can be combined with other
queries.
  • Loading branch information
sammarshallou committed Sep 2, 2014
1 parent c13ac85 commit 1a7049a
Show file tree
Hide file tree
Showing 13 changed files with 549 additions and 20 deletions.
30 changes: 30 additions & 0 deletions availability/classes/info.php
Original file line number Diff line number Diff line change
Expand Up @@ -590,6 +590,36 @@ public function filter_user_list(array $users) {
return $result;
}

/**
* Obtains SQL that returns a list of enrolled users that has been filtered
* by the conditions applied in the availability API, similar to calling
* get_enrolled_users and then filter_user_list. As for filter_user_list,
* this ONLY filteres out users with conditions that are marked as applying
* to user lists. For example, group conditions are included but date
* conditions are not included.
*
* The returned SQL is a query that returns a list of user IDs. It does not
* include brackets, so you neeed to add these to make it into a subquery.
* You would normally use it in an SQL phrase like "WHERE u.id IN ($sql)".
*
* The function returns an array with '' and an empty array, if there are
* no restrictions on users from these conditions.
*
* The SQL will be complex and may be slow. It uses named parameters (sorry,
* I know they are annoying, but it was unavoidable here).
*
* @param bool $onlyactive True if including only active enrolments
* @return array Array of SQL code (may be empty) and params
*/
public function get_user_list_sql($onlyactive) {
global $CFG;
if (is_null($this->availability) || !$CFG->enableavailability) {
return array('', array());
}
$tree = $this->get_availability_tree();
return $tree->get_user_list_sql(false, $this, $onlyactive);
}

/**
* Formats the $cm->availableinfo string for display. This includes
* filling in the names of any course-modules that might be mentioned.
Expand Down
24 changes: 24 additions & 0 deletions availability/classes/info_module.php
Original file line number Diff line number Diff line change
Expand Up @@ -109,6 +109,30 @@ public function filter_user_list(array $users) {
return parent::filter_user_list($filtered);
}

public function get_user_list_sql($onlyactive = true) {
global $CFG, $DB;
if (!$CFG->enableavailability) {
return array('', array());
}

// Get query for section (if any) and module.
$section = $this->cm->get_modinfo()->get_section_info(
$this->cm->sectionnum, MUST_EXIST);
$sectioninfo = new info_section($section);
$sectionresult = $sectioninfo->get_user_list_sql($onlyactive);
$moduleresult = parent::get_user_list_sql($onlyactive);

if (!$sectionresult[0]) {
return $moduleresult;
}
if (!$moduleresult[0]) {
return $sectionresult;
}

return array('(' . $sectionresult[0] . ') INTERSECT (' . $moduleresult[0] . ')',
array_merge($sectionresult[1], $moduleresult[1]));
}

/**
* Checks if an activity is visible to the given user.
*
Expand Down
46 changes: 46 additions & 0 deletions availability/classes/tree.php
Original file line number Diff line number Diff line change
Expand Up @@ -350,6 +350,52 @@ public function filter_user_list(array $users, $not, info $info,
}
}

public function get_user_list_sql($not, info $info, $onlyactive) {
// Get logic flags from operator.
list($innernot, $andoperator) = $this->get_logic_flags($not);

// Loop through all valid children, getting SQL for each.
$childresults = array();
foreach ($this->children as $index => $child) {
if (!$child->is_applied_to_user_lists()) {
continue;
}
$childresult = $child->get_user_list_sql($innernot, $info, $onlyactive);
if ($childresult[0]) {
$childresults[] = $childresult;
} else if (!$andoperator) {
// When using OR operator, if any part doesn't have restrictions,
// then nor does the whole thing.
return array('', array());
}
}

// If there are no conditions, return null.
if (!$childresults) {
return array('', array());
}
// If there is a single condition, return it.
if (count($childresults) === 1) {
return $childresults[0];
}

// Combine results using INTERSECT or UNION.
$outsql = null;
$outparams = null;
foreach ($childresults as $childresult) {
if (!$outsql) {
$outsql = '(' . $childresult[0] . ')';
$outparams = $childresult[1];
} else {
$outsql .= $andoperator ? ' INTERSECT (' : ' UNION (';
$outsql .= $childresult[0];
$outsql .= ')';
$outparams = array_merge($outparams, $childresult[1]);
}
}
return array($outsql, $outparams);
}

public function is_available_for_all($not = false) {
// Get logic flags.
list($innernot, $andoperator) = $this->get_logic_flags($not);
Expand Down
56 changes: 56 additions & 0 deletions availability/classes/tree_node.php
Original file line number Diff line number Diff line change
Expand Up @@ -159,4 +159,60 @@ public function filter_user_list(array $users, $not,
throw new \coding_exception('Not implemented (do not call unless '.
'is_applied_to_user_lists is true)');
}

/**
* Obtains SQL that returns a list of enrolled users that has been filtered
* by the conditions applied in the availability API, similar to calling
* get_enrolled_users and then filter_user_list. As for filter_user_list,
* this ONLY filteres out users with conditions that are marked as applying
* to user lists. For example, group conditions are included but date
* conditions are not included.
*
* The returned SQL is a query that returns a list of user IDs. It does not
* include brackets, so you neeed to add these to make it into a subquery.
* You would normally use it in an SQL phrase like "WHERE u.id IN ($sql)".
*
* The SQL will be complex and may be slow. It uses named parameters (sorry,
* I know they are annoying, but it was unavoidable here).
*
* If there are no conditions, the returned result is array('', array()).
*
* @param bool $not True if this condition is applying in negative mode
* @param \core_availability\info $info Item we're checking
* @param bool $onlyactive If true, only returns active enrolments
* @return array Array with two elements: SQL subquery and parameters array
* @throws \coding_exception If called on a condition that doesn't apply to user lists
*/
public function get_user_list_sql($not, \core_availability\info $info, $onlyactive) {
if (!$this->is_applied_to_user_lists()) {
throw new \coding_exception('Not implemented (do not call unless '.
'is_applied_to_user_lists is true)');
}

// Handle situation where plugin does not implement this, by returning a
// default (all enrolled users). This ensures compatibility with 2.7
// plugins and behaviour. Plugins should be updated to support this
// new function (if they return true to is_applied_to_user_lists).
debugging('Availability plugins that return true to is_applied_to_user_lists ' .
'should also now implement get_user_list_sql: ' . get_class($this),
DEBUG_DEVELOPER);
return get_enrolled_sql($info->get_context(), '', 0, $onlyactive);
}

/**
* Utility function for generating SQL parameters (because we can't use ?
* parameters because get_enrolled_sql has infected us with horrible named
* parameters).
*
* @param array $params Params array (value will be added to this array)
* @param string|int $value Value
* @return SQL code for the parameter, e.g. ':pr1234'
*/
protected static function unique_sql_parameter(array &$params, $value) {
static $count = 1;
$unique = 'usp' . $count;
$params[$unique] = $value;
$count++;
return ':' . $unique;
}
}
36 changes: 36 additions & 0 deletions availability/condition/group/classes/condition.php
Original file line number Diff line number Diff line change
Expand Up @@ -225,4 +225,40 @@ public function filter_user_list(array $users, $not, \core_availability\info $in
public static function get_json($groupid = 0) {
return (object)array('type' => 'group', 'id' => (int)$groupid);
}

public function get_user_list_sql($not, \core_availability\info $info, $onlyactive) {
global $DB;

// Get enrolled users with access all groups. These always are allowed.
list($aagsql, $aagparams) = get_enrolled_sql(
$info->get_context(), 'moodle/site:accessallgroups', 0, $onlyactive);

// Get all enrolled users.
list ($enrolsql, $enrolparams) =
get_enrolled_sql($info->get_context(), '', 0, $onlyactive);

// Condition for specified or any group.
$matchparams = array();
if ($this->groupid) {
$matchsql = "SELECT 1
FROM {groups_members} gm
WHERE gm.userid = userids.id
AND gm.groupid = " .
self::unique_sql_parameter($matchparams, $this->groupid);
} else {
$matchsql = "SELECT 1
FROM {groups_members} gm
JOIN {groups} g ON g.id = gm.groupid
WHERE gm.userid = userids.id
AND g.courseid = " .
self::unique_sql_parameter($matchparams, $info->get_course()->id);
}

// Overall query combines all this.
$condition = $not ? 'NOT' : '';
$sql = "SELECT userids.id
FROM ($enrolsql) userids
WHERE (userids.id IN ($aagsql)) OR $condition EXISTS ($matchsql)";
return array($sql, array_merge($enrolparams, $aagparams, $matchparams));
}
}
38 changes: 33 additions & 5 deletions availability/condition/group/tests/condition_test.php
Original file line number Diff line number Diff line change
Expand Up @@ -164,7 +164,8 @@ public function test_update_dependency_id() {
}

/**
* Tests the filter_users (bulk checking) function.
* Tests the filter_users (bulk checking) function. Also tests the SQL
* variant get_user_list_sql.
*/
public function test_filter_users() {
global $DB;
Expand Down Expand Up @@ -205,21 +206,48 @@ public function test_filter_users() {
$cond = new condition((object)array());
$result = array_keys($cond->filter_user_list($allusers, false, $info, $checker));
ksort($result);
$this->assertEquals(array($teacher->id, $students[1]->id, $students[2]->id), $result);
$expected = array($teacher->id, $students[1]->id, $students[2]->id);
$this->assertEquals($expected, $result);

// Test it with get_user_list_sql.
list ($sql, $params) = $cond->get_user_list_sql(false, $info, true);
$result = $DB->get_fieldset_sql($sql, $params);
sort($result);
$this->assertEquals($expected, $result);

// Test NOT version (note that teacher can still access because AAG works
// both ways).
$result = array_keys($cond->filter_user_list($allusers, true, $info, $checker));
ksort($result);
$this->assertEquals(array($teacher->id, $students[0]->id), $result);
$expected = array($teacher->id, $students[0]->id);
$this->assertEquals($expected, $result);

// Test with get_user_list_sql.
list ($sql, $params) = $cond->get_user_list_sql(true, $info, true);
$result = $DB->get_fieldset_sql($sql, $params);
sort($result);
$this->assertEquals($expected, $result);

// Test specific group.
$cond = new condition((object)array('id' => (int)$group1->id));
$result = array_keys($cond->filter_user_list($allusers, false, $info, $checker));
ksort($result);
$this->assertEquals(array($teacher->id, $students[1]->id), $result);
$expected = array($teacher->id, $students[1]->id);
$this->assertEquals($expected, $result);

list ($sql, $params) = $cond->get_user_list_sql(false, $info, true);
$result = $DB->get_fieldset_sql($sql, $params);
sort($result);
$this->assertEquals($expected, $result);

$result = array_keys($cond->filter_user_list($allusers, true, $info, $checker));
ksort($result);
$this->assertEquals(array($teacher->id, $students[0]->id, $students[2]->id), $result);
$expected = array($teacher->id, $students[0]->id, $students[2]->id);
$this->assertEquals($expected, $result);

list ($sql, $params) = $cond->get_user_list_sql(true, $info, true);
$result = $DB->get_fieldset_sql($sql, $params);
sort($result);
$this->assertEquals($expected, $result);
}
}
28 changes: 28 additions & 0 deletions availability/condition/grouping/classes/condition.php
Original file line number Diff line number Diff line change
Expand Up @@ -258,4 +258,32 @@ public static function get_json($groupingid = 0) {
}
return $result;
}

public function get_user_list_sql($not, \core_availability\info $info, $onlyactive) {
global $DB;

// Get enrolled users with access all groups. These always are allowed.
list($aagsql, $aagparams) = get_enrolled_sql(
$info->get_context(), 'moodle/site:accessallgroups', 0, $onlyactive);

// Get all enrolled users.
list ($enrolsql, $enrolparams) =
get_enrolled_sql($info->get_context(), '', 0, $onlyactive);

// Condition for specified or any group.
$matchparams = array();
$matchsql = "SELECT 1
FROM {groups_members} gm
JOIN {groupings_groups} gg ON gg.groupid = gm.groupid
WHERE gm.userid = userids.id
AND gg.groupingid = " .
self::unique_sql_parameter($matchparams, $this->get_grouping_id($info));

// Overall query combines all this.
$condition = $not ? 'NOT' : '';
$sql = "SELECT userids.id
FROM ($enrolsql) userids
WHERE (userids.id IN ($aagsql)) OR $condition EXISTS ($matchsql)";
return array($sql, array_merge($enrolparams, $aagparams, $matchparams));
}
}
32 changes: 28 additions & 4 deletions availability/condition/grouping/tests/condition_test.php
Original file line number Diff line number Diff line change
Expand Up @@ -206,7 +206,8 @@ public function test_update_dependency_id() {
}

/**
* Tests the filter_users (bulk checking) function.
* Tests the filter_users (bulk checking) function. Also tests the SQL
* variant get_user_list_sql.
*/
public function test_filter_users() {
global $DB, $CFG;
Expand Down Expand Up @@ -258,16 +259,39 @@ public function test_filter_users() {
$cond = new condition((object)array('id' => (int)$grouping1->id));
$result = array_keys($cond->filter_user_list($allusers, false, $info, $checker));
ksort($result);
$this->assertEquals(array($teacher->id, $students[1]->id), $result);
$expected = array($teacher->id, $students[1]->id);
$this->assertEquals($expected, $result);

// Test it with get_user_list_sql.
list ($sql, $params) = $cond->get_user_list_sql(false, $info, true);
$result = $DB->get_fieldset_sql($sql, $params);
sort($result);
$this->assertEquals($expected, $result);

// NOT test.
$result = array_keys($cond->filter_user_list($allusers, true, $info, $checker));
ksort($result);
$this->assertEquals(array($teacher->id, $students[0]->id, $students[2]->id), $result);
$expected = array($teacher->id, $students[0]->id, $students[2]->id);
$this->assertEquals($expected, $result);

// NOT with get_user_list_sql.
list ($sql, $params) = $cond->get_user_list_sql(true, $info, true);
$result = $DB->get_fieldset_sql($sql, $params);
sort($result);
$this->assertEquals($expected, $result);

// Test course-module grouping.
$modinfo = get_fast_modinfo($course);
$cm = $modinfo->get_cm($page->cmid);
$info = new \core_availability\info_module($cm);
$result = array_keys($info->filter_user_list($allusers, $course));
$this->assertEquals(array($teacher->id, $students[2]->id), $result);
$expected = array($teacher->id, $students[2]->id);
$this->assertEquals($expected, $result);

// With get_user_list_sql.
list ($sql, $params) = $info->get_user_list_sql(true);
$result = $DB->get_fieldset_sql($sql, $params);
sort($result);
$this->assertEquals($expected, $result);
}
}
Loading

0 comments on commit 1a7049a

Please sign in to comment.