Skip to content

Commit

Permalink
MDL-74143 database: Make get_indexes() to return original column names
Browse files Browse the repository at this point in the history
Sometimes, in order to provide a cross-db behaviour of unique indexes
mixing null and not null columns, we create, under the hood, some
function based indexes.

When that happens get_indexes() is returning the name of the
expression objects used to calculate that function index. But we need
the original column names to be able to compare indexes and get
column dependencies properly.

So, this patch just looks, when the index is unique and function based,
to the expressions (pretty standard CASE statements) and gets the
original column name from it.

Covered with tests.
  • Loading branch information
stronk7 committed Mar 23, 2022
1 parent 25f22a3 commit f8037d3
Show file tree
Hide file tree
Showing 2 changed files with 51 additions and 1 deletion.
17 changes: 16 additions & 1 deletion lib/dml/oci_native_moodle_database.php
Expand Up @@ -438,9 +438,10 @@ public function get_indexes($table) {
$indexes = array();
$tablename = strtoupper($this->prefix.$table);

$sql = "SELECT i.INDEX_NAME, i.UNIQUENESS, c.COLUMN_POSITION, c.COLUMN_NAME, ac.CONSTRAINT_TYPE
$sql = "SELECT i.INDEX_NAME, i.INDEX_TYPE, i.UNIQUENESS, c.COLUMN_POSITION, c.COLUMN_NAME, e.COLUMN_EXPRESSION, ac.CONSTRAINT_TYPE
FROM ALL_INDEXES i
JOIN ALL_IND_COLUMNS c ON c.INDEX_NAME=i.INDEX_NAME
LEFT JOIN ALL_IND_EXPRESSIONS e ON (e.INDEX_NAME = c.INDEX_NAME AND e.COLUMN_POSITION = c.COLUMN_POSITION)
LEFT JOIN ALL_CONSTRAINTS ac ON (ac.TABLE_NAME=i.TABLE_NAME AND ac.CONSTRAINT_NAME=i.INDEX_NAME AND ac.CONSTRAINT_TYPE='P')
WHERE i.TABLE_NAME = '$tablename'
ORDER BY i.INDEX_NAME, c.COLUMN_POSITION";
Expand All @@ -463,6 +464,20 @@ public function get_indexes($table) {
'unique' => ($record['UNIQUENESS'] === 'UNIQUE'),
'columns' => array());
}

// If this is an unique, function-based, index, then we have to look to the expression
// and calculate the column name by parsing it.
if ($record['UNIQUENESS'] === 'UNIQUE' && $record['INDEX_TYPE'] === 'FUNCTION-BASED NORMAL') {
// Only if there is an expression to look.
if (!empty($record['COLUMN_EXPRESSION'])) {
// Let's parse the usual code used for these unique indexes.
$regex = '/^CASE *WHEN .* THEN "(?<column_name>[^"]+)" ELSE NULL END *$/';
if (preg_match($regex, $record['COLUMN_EXPRESSION'], $matches)) {
$record['COLUMN_NAME'] = $matches['column_name'] ?? $record['COLUMN_NAME'];
}
}
}

$indexes[$indexname]['columns'][] = strtolower($record['COLUMN_NAME']);
}

Expand Down
35 changes: 35 additions & 0 deletions lib/dml/tests/dml_test.php
Expand Up @@ -711,6 +711,41 @@ public function test_get_indexes() {
$this->assertSame('id', $composed['columns'][1]);
}

/**
* Let's verify get_indexes() when we mix null and not null columns in unique indexes.
*
* Some databases, for unique indexes of this type, need to create function indexes to
* provide cross-db behaviour. Here we check that those indexes don't break get_indexes().
*
* Note that, strictly speaking, unique indexes on null columns are far from ideal. Both
* conceptually and also in practice, because they cause DBs to use full scans in a
* number of situations. But if we support them, we need to ensure get_indexes() work on them.
*/
public function test_get_indexes_unique_mixed_nullability() {
$DB = $this->tdb;
$dbman = $this->tdb->get_manager();
$table = $this->get_test_table();
$tablename = $table->getName();

$table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$table->add_field('nullable01', XMLDB_TYPE_INTEGER, 10, null, null, null, null);
$table->add_field('nullable02', XMLDB_TYPE_INTEGER, 10, null, null, null, null);
$table->add_field('nonullable01', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, '0');
$table->add_field('nonullable02', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, null, '0');
$table->add_key('primary', XMLDB_KEY_PRIMARY, array('id'));
$indexcolumns = ['nullable01', 'nonullable01', 'nullable02', 'nonullable02'];
$table->add_index('course-id', XMLDB_INDEX_UNIQUE, $indexcolumns);
$dbman->create_table($table);

$indexes = $DB->get_indexes($tablename);
$this->assertIsArray($indexes);
$this->assertCount(1, $indexes);

$index = array_shift($indexes);
$this->assertTrue($index['unique']);
$this->assertSame($indexcolumns, $index['columns']);
}

public function test_get_columns() {
$DB = $this->tdb;
$dbman = $this->tdb->get_manager();
Expand Down

0 comments on commit f8037d3

Please sign in to comment.