Permalink
Browse files

MDL-28949 course completion: Database structure fixes

  • Loading branch information...
1 parent 131bd2f commit 424a19b106003a55d1fbe857a2c66a3ba6450fd3 @srynot4sale srynot4sale committed May 28, 2012
Showing with 153 additions and 5 deletions.
  1. +7 −4 lib/db/install.xml
  2. +70 −0 lib/db/upgrade.php
  3. +75 −0 lib/upgradelib.php
  4. +1 −1 version.php
View
@@ -149,7 +149,8 @@
</KEYS>
<INDEXES>
<INDEX NAME="course" UNIQUE="false" FIELDS="course" NEXT="criteriatype"/>
- <INDEX NAME="criteriatype" UNIQUE="false" FIELDS="criteriatype" PREVIOUS="course"/>
+ <INDEX NAME="criteriatype" UNIQUE="false" FIELDS="criteriatype" PREVIOUS="course" NEXT="coursecriteriatype"/>
+ <INDEX NAME="coursecriteriatype" UNIQUE="true" FIELDS="course, criteriatype" PREVIOUS="criteriatype"/>
</INDEXES>
</TABLE>
<TABLE NAME="course_completion_criteria" COMMENT="Course completion criteria" PREVIOUS="course_completion_aggr_methd" NEXT="course_completion_crit_compl">
@@ -190,7 +191,8 @@
<INDEX NAME="userid" UNIQUE="false" FIELDS="userid" NEXT="course"/>
<INDEX NAME="course" UNIQUE="false" FIELDS="course" PREVIOUS="userid" NEXT="criteriaid"/>
<INDEX NAME="criteriaid" UNIQUE="false" FIELDS="criteriaid" PREVIOUS="course" NEXT="timecompleted"/>
- <INDEX NAME="timecompleted" UNIQUE="false" FIELDS="timecompleted" PREVIOUS="criteriaid"/>
+ <INDEX NAME="timecompleted" UNIQUE="false" FIELDS="timecompleted" PREVIOUS="criteriaid" NEXT="useridcoursecriteriaid"/>
+ <INDEX NAME="useridcoursecriteriaid" UNIQUE="true" FIELDS="userid, course, criteriaid" PREVIOUS="timecompleted"/>
</INDEXES>
</TABLE>
<TABLE NAME="course_completion_notify" COMMENT="Course completion notification emails" PREVIOUS="course_completion_crit_compl" NEXT="course_completions">
@@ -226,7 +228,8 @@
<INDEXES>
<INDEX NAME="userid" UNIQUE="false" FIELDS="userid" NEXT="course"/>
<INDEX NAME="course" UNIQUE="false" FIELDS="course" PREVIOUS="userid" NEXT="timecompleted"/>
- <INDEX NAME="timecompleted" UNIQUE="false" FIELDS="timecompleted" PREVIOUS="course"/>
+ <INDEX NAME="timecompleted" UNIQUE="false" FIELDS="timecompleted" PREVIOUS="course" NEXT="useridcourse"/>
+ <INDEX NAME="useridcourse" UNIQUE="true" FIELDS="userid, course" PREVIOUS="timecompleted"/>
</INDEXES>
</TABLE>
<TABLE NAME="enrol" COMMENT="Instances of enrolment plugins used in courses, fields marked as custom have a plugin defined meaning, core does not touch them. Create a new linked table if you need even more custom fields." PREVIOUS="course_completions" NEXT="user_enrolments">
@@ -2867,4 +2870,4 @@
</KEYS>
</TABLE>
</TABLES>
-</XMLDB>
+</XMLDB>
View
@@ -648,5 +648,75 @@ function xmldb_main_upgrade($oldversion) {
upgrade_main_savepoint(true, 2012052100.00);
}
+
+ /**
+ * Major clean up of course completion tables
+ */
+ if ($oldversion < 2012052500.02) {
+
+ // Clean up all instances of duplicate records
+ // Add indexes to prevent new duplicates
+ upgrade_course_completion_remove_duplicates(
+ 'course_completions',
+ array('userid', 'course'),
+ array('timecompleted', 'timestarted', 'timeenrolled')
+ );
+
+ // Define index useridcourse (unique) to be added to course_completions
+ $table = new xmldb_table('course_completions');
+ $index = new xmldb_index('useridcourse', XMLDB_INDEX_UNIQUE, array('userid', 'course'));
+
+
+ // Conditionally launch add index useridcourse
+ if (!$dbman->index_exists($table, $index)) {
+ $dbman->add_index($table, $index);
+ }
+
+ // Main savepoint reached
+ upgrade_main_savepoint(true, 2012052500.02);
+ }
+
+ if ($oldversion < 2012052500.03) {
+
+ upgrade_course_completion_remove_duplicates(
+ 'course_completion_crit_compl',
+ array('userid', 'course', 'criteriaid'),
+ array('timecompleted')
+ );
+
+
+ // Define index useridcoursecriteraid (unique) to be added to course_completion_crit_compl
+ $table = new xmldb_table('course_completion_crit_compl');
+ $index = new xmldb_index('useridcoursecriteraid', XMLDB_INDEX_UNIQUE, array('userid', 'course', 'criteriaid'));
+
+ // Conditionally launch add index useridcoursecriteraid
+ if (!$dbman->index_exists($table, $index)) {
+ $dbman->add_index($table, $index);
+ }
+
+ // Main savepoint reached
+ upgrade_main_savepoint(true, 2012052500.03);
+ }
+
+ if ($oldversion < 2012052500.04) {
+
+ upgrade_course_completion_remove_duplicates(
+ 'course_completion_aggr_methd',
+ array('course', 'criteriatype')
+ );
+
+ // Define index coursecriteratype (unique) to be added to course_completion_aggr_methd
+ $table = new xmldb_table('course_completion_aggr_methd');
+ $index = new xmldb_index('coursecriteriatype', XMLDB_INDEX_UNIQUE, array('course', 'criteriatype'));
+
+ // Conditionally launch add index coursecriteratype
+ if (!$dbman->index_exists($table, $index)) {
+ $dbman->add_index($table, $index);
+ }
+
+ // Main savepoint reached
+ upgrade_main_savepoint(true, 2012052500.04);
+ }
+
return true;
}
View
@@ -1764,3 +1764,78 @@ function admin_mnet_method_profile(Zend_Server_Reflection_Function_Abstract $fun
}
return $profile;
}
+
+
+/**
+ * This function finds duplicate records (based on combinations of fields that should be unique)
+ * and then progamatically generated a "most correct" version of the data, update and removing
+ * records as appropriate
+ *
+ * Thanks to Dan Marsden for help
+ *
+ * @param string $table Table name
+ * @param array $uniques Array of field names that should be unique
+ * @param array $feildstocheck Array of fields to generate "correct" data from (optional)
+ * @return void
+ */
+function upgrade_course_completion_remove_duplicates($table, $uniques, $fieldstocheck = array()) {
+ global $DB;
+
+ // Find duplicates
+ $sql_cols = implode(', ', $uniques);
+
+ $sql = "SELECT {$sql_cols} FROM {{$table}} GROUP BY {$sql_cols} HAVING (count(id) > 1)";
+ $duplicates = $DB->get_recordset_sql($sql, array());
+
+ // Loop through duplicates
+ foreach ($duplicates as $duplicate) {
+ $pointer = 0;
+
+ // Generate SQL for finding records with these duplicate uniques
+ $sql_select = implode(' = ? AND ', $uniques).' = ?'; /// builds "fieldname = ? AND fieldname = ?"
+ $uniq_values = array();
+ foreach ($uniques as $u) {
+ $uniq_values[] = $duplicate->$u;
+ }
+
+ $sql_order = implode(' DESC, ', $uniques).' DESC'; // builds "fieldname DESC, fieldname DESC"
+
+ // Get records with these duplicate uniques
+ $records = $DB->get_records_select(
+ $table,
+ $sql_select,
+ $uniq_values,
+ $sql_order
+ );
+
+ // Loop through and build a "correct" record, deleting the others
+ $needsupdate = false;
+ $origrecord = null;
+ foreach ($records as $record) {
+ $pointer++;
+ if ($pointer === 1) { // keep 1st record but delete all others.
+ $origrecord = $record;
+ } else {
+ // If we have fields to check, update original record
+ if ($fieldstocheck) {
+ // we need to keep the "oldest" of all these fields as the valid completion record.
+ // but we want to ignore null values
+ foreach ($fieldstocheck as $f) {
+ if ($record->$f && (($origrecord->$f > $record->$f) || !$origrecord->$f)) {
+ $origrecord->$f = $record->$f;
+ $needsupdate = true;
+ }
+ }
+ }
+ $DB->delete_records($table, array('id' => $record->id));
+ }
+ }
+ if ($needsupdate || isset($origrecord->reaggregate)) {
+ // If this table has a reaggregate field, update to force recheck on next cron cron
+ if (isset($origrecord->reaggregate)) {
+ $origrecord->reaggregate = time();
+ }
+ $DB->update_record($table, $origrecord);
+ }
+ }
+}
View
@@ -30,7 +30,7 @@
defined('MOODLE_INTERNAL') || die();
-$version = 2012052500.01; // YYYYMMDD = weekly release date of this DEV branch
+$version = 2012052500.04; // YYYYMMDD = weekly release date of this DEV branch
// RR = release increments - 00 in DEV branches
// .XX = incremental changes

0 comments on commit 424a19b

Please sign in to comment.