diff --git a/app/config/schema/schema.json b/app/config/schema/schema.json index bae9ccfdc..ba50b9212 100644 --- a/app/config/schema/schema.json +++ b/app/config/schema/schema.json @@ -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 @@ -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" ] } } } }, diff --git a/app/src/Lib/Util/CmgMySQLSchemaManager.php b/app/src/Lib/Util/CmgMySQLSchemaManager.php new file mode 100644 index 000000000..e8169a56e --- /dev/null +++ b/app/src/Lib/Util/CmgMySQLSchemaManager.php @@ -0,0 +1,76 @@ + $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); + } + +} \ No newline at end of file diff --git a/app/src/Lib/Util/CmgPostgreSQLSchemaManager.php b/app/src/Lib/Util/CmgPostgreSQLSchemaManager.php new file mode 100644 index 000000000..a1c946264 --- /dev/null +++ b/app/src/Lib/Util/CmgPostgreSQLSchemaManager.php @@ -0,0 +1,110 @@ + $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 + */ + 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; + } +} + diff --git a/app/src/Lib/Util/CmgSchemaManagerFactory.php b/app/src/Lib/Util/CmgSchemaManagerFactory.php new file mode 100644 index 000000000..e373951e6 --- /dev/null +++ b/app/src/Lib/Util/CmgSchemaManagerFactory.php @@ -0,0 +1,41 @@ +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); + } +} diff --git a/app/src/Lib/Util/SchemaManager.php b/app/src/Lib/Util/SchemaManager.php index 1819ecf86..416f4e95a 100644 --- a/app/src/Lib/Util/SchemaManager.php +++ b/app/src/Lib/Util/SchemaManager.php @@ -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; @@ -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. * @@ -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'], @@ -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(); } /** @@ -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"; @@ -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 @@ -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