Skip to content

CFM-306_Identifier_Assignment_Case_Insensitivity #134

Open
wants to merge 8 commits into
base: develop
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
11 changes: 6 additions & 5 deletions app/config/schema/schema.json
Expand Up @@ -442,7 +442,8 @@
"identifiers_i1": { "columns": [ "identifier", "type_id", "person_id" ] },
"identifiers_i2": { "columns": [ "identifier", "type_id", "external_identity_id" ] },
"identifiers_i3": { "columns": [ "type_id" ] },
"identifiers_i4": { "needed": false, "columns": [ "provisioning_target_id" ] }
"identifiers_i4": { "needed": false, "columns": [ "provisioning_target_id" ] },
"identifiers_i5": { "columns": [ "lower(identifier)", "type_id" ] }
},
"mvea": [ "person", "external_identity", "group" ],
"sourced": true
Expand Down Expand Up @@ -649,16 +650,16 @@
"columns": {
"id": {},
"external_identity_source_id": { "type": "integer", "foreignkey": { "table": "external_identity_sources", "column": "id" }, "notnull": true },
"source_key": { "type": "string", "size": 1024 },
"source_key": { "type": "string", "size": 1022 },
"source_record": { "type": "text" },
"last_update": { "type": "datetime" },
"external_identity_id": {},
"reference_identifier": {}
},
"indexes": {
"ext_identity_sources_records_i1": { "columns": [ "external_identity_source_id" ] },
"ext_identity_sources_records_i2": { "columns": [ "external_identity_id" ] },
"ext_identity_sources_records_i3": { "columns": [ "external_identity_source_id", "source_key" ] }
"ext_identity_source_records_i1": { "columns": [ "external_identity_source_id" ] },
"ext_identity_source_records_i2": { "columns": [ "external_identity_id" ] },
"ext_identity_source_records_i3": { "columns": [ "external_identity_source_id", "source_key" ] }
}
}
},
Expand Down
76 changes: 76 additions & 0 deletions app/src/Lib/Util/CmgMySQLSchemaManager.php
@@ -0,0 +1,76 @@
<?php

namespace App\Lib\Util;

use Doctrine\DBAL\Platforms\AbstractPlatform;
use Doctrine\DBAL\Result;
use Doctrine\DBAL\Schema\AbstractSchemaManager;
use Doctrine\DBAL\Schema\Identifier;
use Doctrine\DBAL\Schema\MySQLSchemaManager;

class CmgMySQLSchemaManager extends MySQLSchemaManager {
/**
* Aggregates and groups the index results according to the required data result.
* Parameters: \mixed[][] $tableIndexes
* null|string $tableName
*/

protected function _getPortableTableIndexesList($tableIndexes, $tableName = null)
{
foreach ($tableIndexes as $k => $v) {
$v = array_change_key_case($v, CASE_LOWER);
if ($v['key_name'] === 'PRIMARY') {
$v['primary'] = true;
} else {
$v['primary'] = false;
}

if (strpos($v['index_type'], 'FULLTEXT') !== false) {
$v['flags'] = ['FULLTEXT'];
} elseif (strpos($v['index_type'], 'SPATIAL') !== false) {
$v['flags'] = ['SPATIAL'];
}

// Ignore prohibited prefix `length` for spatial index
if (strpos($v['index_type'], 'SPATIAL') === false) {
$v['length'] = isset($v['sub_part']) ? (int) $v['sub_part'] : null;
}

$tableIndexes[$k] = $v;
}

return AbstractSchemaManager::_getPortableTableIndexesList($tableIndexes, $tableName);
}

protected function selectIndexColumns(string $databaseName, ?string $tableName = null): Result
{
$sql = 'SELECT';

if ($tableName === null) {
$sql .= ' TABLE_NAME,';
}

$sql .= <<<'SQL'
NON_UNIQUE AS Non_Unique,
INDEX_NAME AS Key_name,
CONCAT(COALESCE(COLUMN_NAME, ''), COALESCE(CONCAT('(', EXPRESSION, ')' ), '')) AS Column_Name,
SUB_PART AS Sub_Part,
INDEX_TYPE AS Index_Type,
EXPRESSION AS Expression
FROM information_schema.STATISTICS
SQL;

$conditions = ['TABLE_SCHEMA = ?'];
$params = [$databaseName];

if ($tableName !== null) {
$conditions[] = 'TABLE_NAME = ?';
$params[] = $tableName;
}

$sql .= ' WHERE ' . implode(' AND ', $conditions) . ' ORDER BY SEQ_IN_INDEX';

return $this->_conn->executeQuery($sql, $params);
}

}
110 changes: 110 additions & 0 deletions app/src/Lib/Util/CmgPostgreSQLSchemaManager.php
@@ -0,0 +1,110 @@
<?php

namespace App\Lib\Util;

use Doctrine\DBAL\Platforms\AbstractPlatform;
use Doctrine\DBAL\Result;
use Doctrine\DBAL\Schema\AbstractSchemaManager;
use Doctrine\DBAL\Schema\Identifier;
use Doctrine\DBAL\Schema\PostgreSQLSchemaManager;

class CmgPostgreSQLSchemaManager extends PostgreSQLSchemaManager {
/**
* {@inheritDoc}
*
* @link http://ezcomponents.org/docs/api/trunk/DatabaseSchema/ezcDbSchemaPgsqlReader.html
*/
protected function _getPortableTableIndexesList($tableIndexes, $tableName = null)
{
$buffer = [];
foreach ($tableIndexes as $row) {
$colNumbers = array_map('intval', explode(' ', $row['indkey']));
$colNames = explode("," , trim($row["indkey_names"], "{,}"));
$colNumName = array_combine($colNumbers, $colNames);

// required for getting the order of the columns right.
foreach ($colNumName as $colNum => $colName) {
$buffer[] = [
'key_name' => $row['relname'],
'column_name' => trim($colName),
'non_unique' => ! $row['indisunique'],
'primary' => $row['indisprimary'],
'where' => $row['where'],
];
}
}

return AbstractSchemaManager::_getPortableTableIndexesList($buffer, $tableName);
}


protected function selectIndexColumns(string $databaseName, ?string $tableName = null): Result
{
$sql = 'SELECT';

if ($tableName === null) {
$sql .= ' tc.relname AS table_name, tn.nspname AS schema_name,';
}

$sql .= <<<'SQL'
quote_ident(ic.relname) AS relname,
i.indisunique,
i.indisprimary,
i.indkey,
i.indexprs,
i.indrelid,
ARRAY(
SELECT regexp_replace(pg_get_indexdef(i.indexrelid, k + 1, true),
'::.*[^()]', -- regular expression tha matches the type of the column
'', -- replace with empty space
'g')
FROM generate_subscripts(i.indkey, 1) as k
ORDER BY k
) AS indkey_names,
pg_get_expr(indpred, indrelid) AS "where"
FROM pg_index i
JOIN pg_class AS tc ON tc.oid = i.indrelid
JOIN pg_namespace tn ON tn.oid = tc.relnamespace
JOIN pg_class AS ic ON ic.oid = i.indexrelid
WHERE ic.oid IN (
SELECT indexrelid
FROM pg_index i, pg_class c, pg_namespace n
SQL;

$conditions = array_merge([
'c.oid = i.indrelid',
'c.relnamespace = n.oid',
], $this->buildQueryConditions($tableName));

$sql .= ' WHERE ' . implode(' AND ', $conditions) . ')';

return $this->_conn->executeQuery($sql);
}

/**
* @param string|null $tableName
*
* @return list<string>
*/
private function buildQueryConditions($tableName): array
{
$conditions = [];

if ($tableName !== null) {
if (strpos($tableName, '.') !== false) {
[$schemaName, $tableName] = explode('.', $tableName);
$conditions[] = 'n.nspname = ' . $this->_platform->quoteStringLiteral($schemaName);
} else {
$conditions[] = 'n.nspname = ANY(current_schemas(false))';
}

$identifier = new Identifier($tableName);
$conditions[] = 'c.relname = ' . $this->_platform->quoteStringLiteral($identifier->getName());
}

$conditions[] = "n.nspname NOT IN ('pg_catalog', 'information_schema', 'pg_toast')";

return $conditions;
}
}

41 changes: 41 additions & 0 deletions app/src/Lib/Util/CmgSchemaManagerFactory.php
@@ -0,0 +1,41 @@
<?php

namespace App\Lib\Util;

use App\Lib\Util\CmgPostgreSQLSchemaManager;
use App\Lib\Util\CmgMySQLSchemaManager;
use Doctrine\DBAL\Driver\AbstractPostgreSQLDriver;
use Doctrine\DBAL\Platforms\AbstractPlatform;
use Doctrine\DBAL\Platforms\MySQL80Platform;
use Doctrine\DBAL\Platforms\MySQLPlatform;
use Doctrine\DBAL\Schema\AbstractSchemaManager;
use Doctrine\DBAL\Schema\DefaultSchemaManagerFactory;
use Doctrine\DBAL\Schema\SchemaManagerFactory;
use Doctrine\DBAL\Connection;
use Doctrine\DBAL\Platforms\PostgreSQLPlatform;
use Doctrine\DBAL\Platforms\PostgreSQL100Platform;

final class CmgSchemaManagerFactory implements SchemaManagerFactory
{
private readonly SchemaManagerFactory $defaultFactory;

public function __construct()
{
$this->defaultFactory = new DefaultSchemaManagerFactory();
}

public function createSchemaManager(Connection $connection): AbstractSchemaManager
{
$platform = $connection->getDatabasePlatform();
if ($platform instanceof PostgreSQL1000Platform
|| $platform instanceof PostgreSQLPlatform) {
return new CmgPostgreSQLSchemaManager($connection, $platform);
}

if ($platform instanceof MySQLPlatform) {
return new CmgMySQLSchemaManager($connection, $platform);
}

return $this->defaultFactory->createSchemaManager($connection);
}
}
59 changes: 49 additions & 10 deletions app/src/Lib/Util/SchemaManager.php
Expand Up @@ -32,6 +32,7 @@
use Cake\Console\ConsoleIo;
use Cake\Datasource\ConnectionInterface;
use Cake\Datasource\ConnectionManager;
use App\Lib\Util\CmgSchemaManagerFactory;

use Doctrine\DBAL\DriverManager;
use Doctrine\DBAL\Schema\Comparator;
Expand Down Expand Up @@ -61,6 +62,9 @@ class SchemaManager {
// The column library from the main config
protected $columnLibrary = null;

// The current platform
protected $platform = null;

/**
* Construct a new SchemaManager.
*
Expand All @@ -79,7 +83,9 @@ public function __construct(?ConsoleIo $io=null, string $connection='default') {
$cfg = $db->config();

$config = new \Doctrine\DBAL\Configuration();

// Load the COmanage custom CmgSchemaManagerFactory
$config->setSchemaManagerFactory(new CmgSchemaManagerFactory());

$cfargs = [
'dbname' => $cfg['database'],
'user' => $cfg['username'],
Expand All @@ -95,6 +101,7 @@ public function __construct(?ConsoleIo $io=null, string $connection='default') {

$this->conn = DriverManager::getConnection($cfargs, $config);
$this->driver = $cfg['driver'];
$this->platform = $this->conn->getDatabasePlatform();
}

/**
Expand Down Expand Up @@ -261,18 +268,51 @@ protected function processSchema(
// $flags and $options as passed to Index(), but otherwise undocumented
$flags = [];
$options = [];

// XXX DBAL does not support expression indexes. We will trick DBAL by
// temporary adding the virtual column in the table. This will make
// no difference to the table end result since the actual query list
// will be executed later. What we actually do is treat the expression
// as a temporary virtual column
// https://www.postgresql.org/docs/14/indexes-expressional.html
// https://dev.mysql.com/doc/refman/8.0/en/create-index.html#create-index-functional-key-parts
// https://www.sqlite.org/expridx.html
// XXX MariadBD is not supported
$tempColumns = [];
foreach ($iCfg->columns as $idx => $clm_name) {
if (! $table->hasColumn($clm_name)) {
if(in_array($this->driver, array(
"Cake\Database\Driver\Mysql",
"Cake\Database\Driver\Sqlite",
))) {
// MySQL requires the column name to be wrapped with parenthesis
// Instead of indexing a simple column, you can create the index on the result
// of any function applied to a column or multiple columns.
// Be aware of the double parentheses. The syntax is correct since the expression
// must be enclosed within parentheses to distinguish it from columns or column prefixes.
$iCfg->columns[$idx] = $clm_name = "({$clm_name})";
}
$table->addColumn($clm_name, "string");
$tempColumns[] = $clm_name;
}
}

if(isset($iCfg->unique) && $iCfg->unique) {
$table->addUniqueConstraint($iCfg->columns, $iName, $flags, $options);
} else {
$table->addIndex($iCfg->columns, $iName, $flags, $options);
}

foreach ($tempColumns as $clm_name) {
$table->dropColumn($clm_name);
}
$tempColumns = [];
}
}

// (For Registry) If an attribute is "sourced" it is a CO Person attribute
// that is copied via a Pipeline from an External Identity that was created from
// an External Identity Source, so we need a foreign key into ourself.
// an External Identity Source, so we need a foreign key into ourselves.

if(isset($tCfg->sourced) && $tCfg->sourced) {
$sColumn = "source_" . $tablePrefix.\Cake\Utility\Inflector::singularize($tName) . "_id";
Expand Down Expand Up @@ -305,15 +345,15 @@ protected function processSchema(
}

// This is the SQL that represents the desired state of the database
$toSql = $schema->toSql($this->conn->getDatabasePlatform());
$toSql = $schema->toSql($this->platform);

// SchemaManager provides info about the database
$sm = $this->conn->createSchemaManager();

// This is the current database representation
$curSchema = $sm->introspectSchema();

// The is the current database representation
$curSchema = $sm->createSchema();

$fromSql = $curSchema->toSql($this->conn->getDatabasePlatform());
$fromSql = $curSchema->toSql($this->platform);

try {
// We manually call compare so we can get the SchemaDiff object. We need
Expand All @@ -322,8 +362,7 @@ protected function processSchema(
// schema file).
$comparator = new Comparator();
$schemaDiff = $comparator->compareSchemas($curSchema, $schema);

$diffSql = $schemaDiff->toSaveSql($this->conn->getDatabasePlatform());
$diffSql = $this->platform->getAlterSchemaSQL($schemaDiff);

// We don't start a transaction since in general we always want to move to
// the desired state, and if we fail in flight it's probably a bug that
Expand Down