Skip to content

Commit

Permalink
MDL-71696 core_question: Implement new database schema
Browse files Browse the repository at this point in the history
This commit implements the new database structure for
versioning in question. It also does the migration of
current data to the new structure.

Co-Authored-By: Safat Shahin <safatshahin@catalyst-au.net>
Co-Authored-By: Guillermo Gomez Arias <guillermogomez@catalyst-au.net>
  • Loading branch information
guillogo and safatshahin committed Feb 3, 2022
1 parent c352b70 commit c34b89a
Show file tree
Hide file tree
Showing 8 changed files with 494 additions and 45 deletions.
8 changes: 5 additions & 3 deletions lang/en/question.php
Expand Up @@ -426,9 +426,11 @@
$string['privacy:metadata:database:question_attempts:flagged'] = 'An indication that the user has flagged this question within the attempt.';
$string['privacy:metadata:database:question_attempts:responsesummary'] = 'A summary of the question response.';
$string['privacy:metadata:database:question_attempts:timemodified'] = 'The time that the question attempt was updated.';
$string['privacy:metadata:link:qbehaviour'] = 'The question subsystem makes use of the Question behaviours plugin type.';
$string['privacy:metadata:link:qformat'] = 'The question subsystem makes use of the Question import/export formats plugin type for the purpose of importing and exporting questions in different formats.';
$string['privacy:metadata:link:qtype'] = 'The question subsystem interacts with the Question types plugin type which contains the different types of questions.';
$string['privacy:metadata:database:question_bank_entries'] = 'The details about a specific question bank entry.';
$string['privacy:metadata:database:question_bank_entries:ownerid'] = 'The person who owns the question bank entry.';
$string['privacy:metadata:link:qbehaviour'] = 'The Question subsystem makes use of the Question Behaviour plugintype.';
$string['privacy:metadata:link:qformat'] = 'The Question subsystem makes use of the Question Format plugintype for the purpose of importing and exporting questions in different formats.';
$string['privacy:metadata:link:qtype'] = 'The Question subsystem interacts with the Question Type plugintype which contains the different types of questions.';
$string['questionbehaviouradminsetting'] = 'Question behaviour settings';
$string['questionbehavioursdisabled'] = 'Question behaviours to disable';
$string['questionbehavioursdisabledexplained'] = 'Enter a comma-separated list of behaviours you do not want to appear in the drop-down menu.';
Expand Down
70 changes: 63 additions & 7 deletions lib/db/install.xml
Expand Up @@ -1402,10 +1402,9 @@
<INDEX NAME="contextididnumber" UNIQUE="true" FIELDS="contextid, idnumber"/>
</INDEXES>
</TABLE>
<TABLE NAME="question" COMMENT="The questions themselves">
<TABLE NAME="question" COMMENT="This table stores the definition of one version of a question.">
<FIELDS>
<FIELD NAME="id" TYPE="int" LENGTH="10" NOTNULL="true" SEQUENCE="true"/>
<FIELD NAME="category" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false"/>
<FIELD NAME="parent" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false"/>
<FIELD NAME="name" TYPE="char" LENGTH="255" NOTNULL="true" SEQUENCE="false"/>
<FIELD NAME="questiontext" TYPE="text" NOTNULL="true" SEQUENCE="false"/>
Expand All @@ -1417,26 +1416,83 @@
<FIELD NAME="qtype" TYPE="char" LENGTH="20" NOTNULL="true" SEQUENCE="false"/>
<FIELD NAME="length" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="1" SEQUENCE="false"/>
<FIELD NAME="stamp" TYPE="char" LENGTH="255" NOTNULL="true" SEQUENCE="false"/>
<FIELD NAME="version" TYPE="char" LENGTH="255" NOTNULL="true" SEQUENCE="false"/>
<FIELD NAME="hidden" TYPE="int" LENGTH="1" NOTNULL="true" DEFAULT="0" SEQUENCE="false"/>
<FIELD NAME="timecreated" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" COMMENT="time question was created"/>
<FIELD NAME="timemodified" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" COMMENT="time that question was last modified"/>
<FIELD NAME="createdby" TYPE="int" LENGTH="10" NOTNULL="false" SEQUENCE="false" COMMENT="userid of person who created this question"/>
<FIELD NAME="modifiedby" TYPE="int" LENGTH="10" NOTNULL="false" SEQUENCE="false" COMMENT="userid of person who last edited this question"/>
<FIELD NAME="idnumber" TYPE="char" LENGTH="100" NOTNULL="false" SEQUENCE="false"/>
</FIELDS>
<KEYS>
<KEY NAME="primary" TYPE="primary" FIELDS="id"/>
<KEY NAME="category" TYPE="foreign" FIELDS="category" REFTABLE="question_categories" REFFIELDS="id"/>
<KEY NAME="parent" TYPE="foreign" FIELDS="parent" REFTABLE="question" REFFIELDS="id" COMMENT="note that to make this recursive FK working someday, the parent field must be declared NULL"/>
<KEY NAME="createdby" TYPE="foreign" FIELDS="createdby" REFTABLE="user" REFFIELDS="id" COMMENT="foreign (createdby) references user (id)"/>
<KEY NAME="modifiedby" TYPE="foreign" FIELDS="modifiedby" REFTABLE="user" REFFIELDS="id" COMMENT="foreign (modifiedby) references user (id)"/>
</KEYS>
<INDEXES>
<INDEX NAME="qtype" UNIQUE="false" FIELDS="qtype"/>
<INDEX NAME="categoryidnumber" UNIQUE="true" FIELDS="category, idnumber"/>
</INDEXES>
</TABLE>
<TABLE NAME="question_bank_entries" COMMENT="Each question bank entry. This table has one row for each question that appears in the question bank.">
<FIELDS>
<FIELD NAME="id" TYPE="int" LENGTH="10" NOTNULL="true" SEQUENCE="true"/>
<FIELD NAME="questioncategoryid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" COMMENT="ID of the category this question is part of."/>
<FIELD NAME="idnumber" TYPE="char" LENGTH="100" NOTNULL="false" SEQUENCE="false" COMMENT="Unique identifier, useful especially for mapping to external entities."/>
<FIELD NAME="ownerid" TYPE="int" LENGTH="10" NOTNULL="false" SEQUENCE="false" COMMENT="userid of person who owns this question bank entry."/>
</FIELDS>
<KEYS>
<KEY NAME="primary" TYPE="primary" FIELDS="id"/>
<KEY NAME="questioncategoryid" TYPE="foreign" FIELDS="questioncategoryid" REFTABLE="question_categories" REFFIELDS="id"/>
<KEY NAME="ownerid" TYPE="foreign" FIELDS="ownerid" REFTABLE="user" REFFIELDS="id"/>
</KEYS>
<INDEXES>
<INDEX NAME="categoryidnumber" UNIQUE="true" FIELDS="questioncategoryid, idnumber"/>
</INDEXES>
</TABLE>
<TABLE NAME="question_versions" COMMENT="A join table linking the different question version definitions in the question table to the question_bank_entires.">
<FIELDS>
<FIELD NAME="id" TYPE="int" LENGTH="10" NOTNULL="true" SEQUENCE="true"/>
<FIELD NAME="questionbankentryid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" COMMENT="ID of the question bank entry this question version is part of."/>
<FIELD NAME="version" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="1" SEQUENCE="false" COMMENT="Version number for the question where the first version is always 1."/>
<FIELD NAME="questionid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" COMMENT="The question ID."/>
<FIELD NAME="status" TYPE="char" LENGTH="10" NOTNULL="false" DEFAULT="ready" SEQUENCE="false" COMMENT="If the question is ready, hidden or draft"/>
</FIELDS>
<KEYS>
<KEY NAME="primary" TYPE="primary" FIELDS="id"/>
<KEY NAME="questionbankentryid" TYPE="foreign" FIELDS="questionbankentryid" REFTABLE="question_bank_entries" REFFIELDS="id"/>
<KEY NAME="questionid" TYPE="foreign" FIELDS="questionid" REFTABLE="question" REFFIELDS="id"/>
</KEYS>
</TABLE>
<TABLE NAME="question_references" COMMENT="Records where a specific question is used.">
<FIELDS>
<FIELD NAME="id" TYPE="int" LENGTH="10" NOTNULL="true" SEQUENCE="true"/>
<FIELD NAME="usingcontextid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" COMMENT="Context where question is used."/>
<FIELD NAME="component" TYPE="char" LENGTH="100" NOTNULL="false" SEQUENCE="false" COMMENT="Component (e.g. mod_quiz or core_question)"/>
<FIELD NAME="questionarea" TYPE="char" LENGTH="50" NOTNULL="false" SEQUENCE="false" COMMENT="Depending on the component, which area the question is used in (e.g. slot for quiz)."/>
<FIELD NAME="itemid" TYPE="int" LENGTH="10" NOTNULL="false" SEQUENCE="false" COMMENT="Plugin specific id (e.g. slotid for quiz) where its used."/>
<FIELD NAME="questionbankentryid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" COMMENT="ID of the question bank entry this question is part of."/>
<FIELD NAME="version" TYPE="int" LENGTH="10" NOTNULL="false" SEQUENCE="false" COMMENT="Version number for the question where NULL means use the latest ready version."/>
</FIELDS>
<KEYS>
<KEY NAME="primary" TYPE="primary" FIELDS="id"/>
<KEY NAME="usingcontextid" TYPE="foreign" FIELDS="usingcontextid" REFTABLE="context" REFFIELDS="id"/>
<KEY NAME="questionbankentryid" TYPE="foreign" FIELDS="questionbankentryid" REFTABLE="question_bank_entries" REFFIELDS="id"/>
</KEYS>
</TABLE>
<TABLE NAME="question_set_references" COMMENT="Records where groups of questions are used.">
<FIELDS>
<FIELD NAME="id" TYPE="int" LENGTH="10" NOTNULL="true" SEQUENCE="true"/>
<FIELD NAME="usingcontextid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" COMMENT="Context where question is used."/>
<FIELD NAME="component" TYPE="char" LENGTH="100" NOTNULL="false" SEQUENCE="false" COMMENT="Component (e.g. mod_quiz)"/>
<FIELD NAME="questionarea" TYPE="char" LENGTH="50" NOTNULL="false" SEQUENCE="false" COMMENT="Depending on the component, which area the question is used in (e.g. slot for quiz)."/>
<FIELD NAME="itemid" TYPE="int" LENGTH="10" NOTNULL="false" SEQUENCE="false" COMMENT="Plugin specific id (e.g. slotid for quiz) where its used."/>
<FIELD NAME="questionscontextid" TYPE="int" LENGTH="10" NOTNULL="true" DEFAULT="0" SEQUENCE="false" COMMENT="Context questions come from."/>
<FIELD NAME="filtercondition" TYPE="text" NOTNULL="false" SEQUENCE="false" COMMENT="Filter expression in json format"/>
</FIELDS>
<KEYS>
<KEY NAME="primary" TYPE="primary" FIELDS="id"/>
<KEY NAME="usingcontextid" TYPE="foreign" FIELDS="usingcontextid" REFTABLE="context" REFFIELDS="id"/>
<KEY NAME="questionscontextid" TYPE="foreign" FIELDS="questionscontextid" REFTABLE="context" REFFIELDS="id"/>
</KEYS>
</TABLE>
<TABLE NAME="question_answers" COMMENT="Answers, with a fractional grade (0-1) and feedback">
<FIELDS>
<FIELD NAME="id" TYPE="int" LENGTH="10" NOTNULL="true" SEQUENCE="true"/>
Expand Down
153 changes: 153 additions & 0 deletions lib/db/upgrade.php
Expand Up @@ -3809,5 +3809,158 @@ function xmldb_main_upgrade($oldversion) {
upgrade_main_savepoint(true, 2022012100.02);
}

// Introduce question versioning to core.
// First, create the new tables.
if ($oldversion < 2022020200.01) {
// Define table question_bank_entries to be created.
$table = new xmldb_table('question_bank_entries');

// Adding fields to table question_bank_entries.
$table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$table->add_field('questioncategoryid', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, 0);
$table->add_field('idnumber', XMLDB_TYPE_CHAR, '100', null, null, null, null);
$table->add_field('ownerid', XMLDB_TYPE_INTEGER, '10', null, null, null, null);

// Adding keys to table question_bank_entries.
$table->add_key('primary', XMLDB_KEY_PRIMARY, ['id']);
$table->add_key('questioncategoryid', XMLDB_KEY_FOREIGN, ['questioncategoryid'], 'question_categories', ['id']);
$table->add_key('ownerid', XMLDB_KEY_FOREIGN, ['ownerid'], 'user', ['id']);

// Conditionally launch create table for question_bank_entries.
if (!$dbman->table_exists($table)) {
$dbman->create_table($table);
}

// Create category id and id number index.
$index = new xmldb_index('categoryidnumber', XMLDB_INDEX_UNIQUE, ['questioncategoryid', 'idnumber']);

// Conditionally launch add index categoryidnumber.
if (!$dbman->index_exists($table, $index)) {
$dbman->add_index($table, $index);
}

// Define table question_versions to be created.
$table = new xmldb_table('question_versions');

// Adding fields to table question_versions.
$table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$table->add_field('questionbankentryid', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, null);
$table->add_field('version', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, 1);
$table->add_field('questionid', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, 0);
$table->add_field('status', XMLDB_TYPE_CHAR, '10', null, XMLDB_NOTNULL, null, 'ready');

// Adding keys to table question_versions.
$table->add_key('primary', XMLDB_KEY_PRIMARY, ['id']);
$table->add_key('questionbankentryid', XMLDB_KEY_FOREIGN, ['questionbankentryid'], 'question_bank_entries', ['id']);
$table->add_key('questionid', XMLDB_KEY_FOREIGN, ['questionid'], 'question', ['id']);

// Conditionally launch create table for question_versions.
if (!$dbman->table_exists($table)) {
$dbman->create_table($table);
}

// Define table question_references to be created.
$table = new xmldb_table('question_references');

// Adding fields to table question_references.
$table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$table->add_field('usingcontextid', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, 0);
$table->add_field('component', XMLDB_TYPE_CHAR, '100', null, null, null, null);
$table->add_field('questionarea', XMLDB_TYPE_CHAR, '50', null, null, null, null);
$table->add_field('itemid', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, null);
$table->add_field('questionbankentryid', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, null);
$table->add_field('version', XMLDB_TYPE_INTEGER, '10', null, null, null, null);

// Adding keys to table question_references.
$table->add_key('primary', XMLDB_KEY_PRIMARY, ['id']);
$table->add_key('usingcontextid', XMLDB_KEY_FOREIGN, ['usingcontextid'], 'context', ['id']);
$table->add_key('questionbankentryid', XMLDB_KEY_FOREIGN, ['questionbankentryid'], 'question_bank_entries', ['id']);

// Conditionally launch create table for question_references.
if (!$dbman->table_exists($table)) {
$dbman->create_table($table);
}

// Define table question_set_references to be created.
$table = new xmldb_table('question_set_references');

// Adding fields to table question_set_references.
$table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$table->add_field('usingcontextid', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, 0);
$table->add_field('component', XMLDB_TYPE_CHAR, '100', null, null, null, null);
$table->add_field('questionarea', XMLDB_TYPE_CHAR, '50', null, null, null, null);
$table->add_field('itemid', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, null);
$table->add_field('questionscontextid', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, 0);
$table->add_field('filtercondition', XMLDB_TYPE_TEXT, null, null, null, null, null);

// Adding keys to table question_set_references.
$table->add_key('primary', XMLDB_KEY_PRIMARY, ['id']);
$table->add_key('usingcontextid', XMLDB_KEY_FOREIGN, ['usingcontextid'], 'context', ['id']);
$table->add_key('itemid', XMLDB_KEY_FOREIGN, ['itemid'], 'quiz_slots', ['id']);
$table->add_key('questionscontextid', XMLDB_KEY_FOREIGN, ['questionscontextid'], 'context', ['id']);

// Conditionally launch create table for question_set_references.
if (!$dbman->table_exists($table)) {
$dbman->create_table($table);
}

// Main savepoint reached.
upgrade_main_savepoint(true, 2022020200.01);
}

if ($oldversion < 2022020200.02) {
// Next, split question records into the new tables.
upgrade_migrate_question_table();
// Main savepoint reached.
upgrade_main_savepoint(true, 2022020200.02);
}

// Finally, drop fields from question table.
if ($oldversion < 2022020200.03) {
// Define fields to be dropped from questions.
$table = new xmldb_table('question');

$field = new xmldb_field('version');
// Conditionally launch drop field version.
if ($dbman->field_exists($table, $field)) {
$dbman->drop_field($table, $field);
}

$field = new xmldb_field('hidden');
// Conditionally launch drop field hidden.
if ($dbman->field_exists($table, $field)) {
$dbman->drop_field($table, $field);
}

// Define index categoryidnumber (not unique) to be dropped form question.
$index = new xmldb_index('categoryidnumber', XMLDB_INDEX_UNIQUE, ['category', 'idnumber']);

// Conditionally launch drop index categoryidnumber.
if ($dbman->index_exists($table, $index)) {
$dbman->drop_index($table, $index);
}

// Define key category (foreign) to be dropped form questions.
$key = new xmldb_key('category', XMLDB_KEY_FOREIGN, ['category'], 'question_categories', ['id']);

// Launch drop key category.
$dbman->drop_key($table, $key);

$field = new xmldb_field('idnumber');
// Conditionally launch drop field idnumber.
if ($dbman->field_exists($table, $field)) {
$dbman->drop_field($table, $field);
}

$field = new xmldb_field('category');
// Conditionally launch drop field category.
if ($dbman->field_exists($table, $field)) {
$dbman->drop_field($table, $field);
}

// Main savepoint reached.
upgrade_main_savepoint(true, 2022020200.03);
}

return true;
}

0 comments on commit c34b89a

Please sign in to comment.