MDL-53451 competency: Fixing database errors on Oracle

- Random ordering caused by absence of ORDER BY clause
- Invalid query statemennt due to wrong string concatenation
- Cannot GROUP BY with CLOB columns
This commit is contained in:
Frederic Massart 2016-04-20 15:16:16 +08:00
parent eb91deaa85
commit 0abaf33e00
5 changed files with 38 additions and 30 deletions

View file

@ -138,24 +138,25 @@ class related_competency extends persistent {
public static function get_related_competencies($competencyid) {
global $DB;
$sql = "(SELECT c.*, " . $DB->sql_concat('rc.relatedcompetencyid', "'_'", 'rc.competencyid') . " AS rid
$fields = competency::get_sql_fields('c', 'c_');
$sql = "(SELECT $fields, " . $DB->sql_concat('rc.relatedcompetencyid', "'_'", 'rc.competencyid') . " AS rid
FROM {" . self::TABLE . "} rc
JOIN {" . competency::TABLE . "} c
ON c.id = rc.relatedcompetencyid
WHERE rc.competencyid = :cid)
UNION ALL
(SELECT c.*, " . $DB->sql_concat('rc.competencyid', "'_'", 'rc.relatedcompetencyid') . " AS rid
(SELECT $fields, " . $DB->sql_concat('rc.competencyid', "'_'", 'rc.relatedcompetencyid') . " AS rid
FROM {" . self::TABLE . "} rc
JOIN {" . competency::TABLE . "} c
ON c.id = rc.competencyid
WHERE rc.relatedcompetencyid = :cid2)
ORDER BY path, sortorder ASC";
ORDER BY c_path ASC, c_sortorder ASC";
$competencies = array();
$records = $DB->get_recordset_sql($sql, array('cid' => $competencyid, 'cid2' => $competencyid));
foreach ($records as $record) {
unset($record->rid);
$competencies[$record->id] = new competency(null, $record);
$competencies[$record->c_id] = new competency(null, competency::extract_record($record, 'c_'));
}
$records->close();

View file

@ -107,6 +107,8 @@ class template_competency extends persistent {
$params[] = 1;
}
$sql .= ' ORDER BY tpl.id ASC';
$results = $DB->get_records_sql($sql, $params);
$instances = array();
@ -199,11 +201,10 @@ class template_competency extends persistent {
FROM {' . competency::TABLE . '} comp
JOIN {' . self::TABLE . '} tplcomp
ON tplcomp.competencyid = comp.id
WHERE tplcomp.templateid = ?';
WHERE tplcomp.templateid = ?
ORDER BY tplcomp.sortorder ASC';
$params = array($templateid);
$sql .= 'ORDER BY tplcomp.sortorder ASC';
$results = $DB->get_records_sql($sql, $params);
$instances = array();

View file

@ -263,24 +263,27 @@ class user_competency_course extends persistent {
public static function get_least_proficient_competencies_for_course($courseid, $skip = 0, $limit = 0) {
global $DB;
$fields = competency::get_sql_fields('c');
$fields = competency::get_sql_fields('c', 'c_');
$params = array('courseid' => $courseid);
$sql = 'SELECT ' . $fields . ', SUM(COALESCE(ucc.proficiency, 0)) AS timesproficient ' .
' FROM {' . competency::TABLE . '} c
JOIN {' . course_competency::TABLE . '} cc
ON c.id = cc.competencyid
LEFT JOIN {' . self::TABLE . '} ucc
ON ucc.competencyid = c.id AND ucc.courseid = cc.courseid
WHERE cc.courseid = :courseid
GROUP BY c.id
ORDER BY timesproficient ASC, c.id DESC';
$sql = 'SELECT ' . $fields . '
FROM (SELECT cc.competencyid, SUM(COALESCE(ucc.proficiency, 0)) AS timesproficient
FROM {' . course_competency::TABLE . '} cc
LEFT JOIN {' . self::TABLE . '} ucc
ON ucc.competencyid = cc.competencyid
AND ucc.courseid = cc.courseid
WHERE cc.courseid = :courseid
GROUP BY cc.competencyid
) p
JOIN {' . competency::TABLE . '} c
ON c.id = p.competencyid
ORDER BY p.timesproficient ASC, c.id DESC';
$results = $DB->get_records_sql($sql, $params, $skip, $limit);
$a = $DB->get_records_sql('SELECT * from {' . self::TABLE . '}');
$comps = array();
foreach ($results as $r) {
$c = competency::extract_record($r);
$c = competency::extract_record($r, 'c_');
$comps[] = new competency(0, $c);
}
return $comps;

View file

@ -340,24 +340,26 @@ class user_competency_plan extends persistent {
public static function get_least_proficient_competencies_for_template($templateid, $skip = 0, $limit = 0) {
global $DB;
$fields = competency::get_sql_fields('c');
$fields = competency::get_sql_fields('c', 'c_');
$params = array('templateid' => $templateid, 'notproficient' => false);
$sql = 'SELECT ' . $fields . ', COUNT(c.id) AS timesnotproficient ' .
' FROM {' . self::TABLE . '} ucp
JOIN {' . plan::TABLE . '} p
ON ucp.planid = p.id
$sql = 'SELECT ' . $fields . '
FROM (SELECT ucp.competencyid, COUNT(ucp.competencyid) AS timesnotproficient
FROM {' . self::TABLE . '} ucp
JOIN {' . plan::TABLE . '} p
ON p.id = ucp.planid
WHERE p.templateid = :templateid
AND (ucp.proficiency = :notproficient OR ucp.proficiency IS NULL)
GROUP BY ucp.competencyid
) p
JOIN {' . competency::TABLE . '} c
ON ucp.competencyid = c.id
WHERE p.templateid = :templateid
AND (ucp.proficiency = :notproficient OR ucp.proficiency IS NULL)
GROUP BY c.id
ORDER BY timesnotproficient DESC';
ON c.id = p.competencyid
ORDER BY p.timesnotproficient DESC, c.id ASC';
$results = $DB->get_records_sql($sql, $params, $skip, $limit);
$comps = array();
foreach ($results as $r) {
$c = competency::extract_record($r);
$c = competency::extract_record($r, 'c_');
$comps[] = new competency(0, $c);
}
return $comps;

View file

@ -122,7 +122,8 @@ class user_evidence_competency extends persistent {
JOIN {" . user_evidence::TABLE . "} ue
ON uec.userevidenceid = ue.id
AND uc.userid = ue.userid
AND ue.id = ?";
AND ue.id = ?
ORDER BY uc.id ASC";
$usercompetencies = array();
$records = $DB->get_recordset_sql($sql, array($userevidenceid));