Skip to content

Commit

Permalink
Fixes #13911: Significantly enhanced MSSQL schema reading performance
Browse files Browse the repository at this point in the history
  • Loading branch information
paulzi authored and samdark committed Apr 19, 2017
1 parent 0cf236e commit 2242019
Show file tree
Hide file tree
Showing 2 changed files with 39 additions and 33 deletions.
3 changes: 2 additions & 1 deletion framework/CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -67,7 +67,8 @@ Yii Framework 2 Change Log
- Enh #13945: Removed Courier New from error page fonts list since it looks bad on Linux (samdark)
- Bug #13961: RBAC Rules: PostgreSQL: PHP Warning "unserialize() expects parameter 1 to be string, resource given" was fixed (vsguts)
- Enh #13976: Disabled IPv6 check on `\yii\validators\IpValidator` as it turns out it is not needed for inet_* methods to work (mikk150)
- Enh #13981: `yii\caching\Cache::getOrSet()` now supports both `Closure` and `callable` (silverfire)
- Enh #13981: `yii\caching\Cache::getOrSet()` now supports both `Closure` and `callable` (silverfire)
- Enh #13911: Significantly enhanced MSSQL schema reading performance (paulzi, WebdevMerlion)

2.0.11.2 February 08, 2017
--------------------------
Expand Down
69 changes: 37 additions & 32 deletions framework/db/mssql/Schema.php
Original file line number Diff line number Diff line change
Expand Up @@ -253,16 +253,22 @@ protected function findColumns($table)

$sql = <<<SQL
SELECT
[t1].[column_name], [t1].[is_nullable], [t1].[data_type], [t1].[column_default],
COLUMNPROPERTY(OBJECT_ID([t1].[table_schema] + '.' + [t1].[table_name]), [t1].[column_name], 'IsIdentity') AS is_identity,
CONVERT(VARCHAR, [t2].[value]) AS comment
[t1].[column_name],
[t1].[is_nullable],
[t1].[data_type],
[t1].[column_default],
COLUMNPROPERTY(OBJECT_ID([t1].[table_schema] + '.' + [t1].[table_name]), [t1].[column_name], 'IsIdentity') AS is_identity,
(
SELECT CONVERT(VARCHAR, [t2].[value])
FROM [sys].[extended_properties] AS [t2]
WHERE
[t2].[class] = 1 AND
[t2].[class_desc] = 'OBJECT_OR_COLUMN' AND
[t2].[name] = 'MS_Description' AND
[t2].[major_id] = OBJECT_ID([t1].[TABLE_SCHEMA] + '.' + [t1].[table_name]) AND
[t2].[minor_id] = COLUMNPROPERTY(OBJECT_ID([t1].[TABLE_SCHEMA] + '.' + [t1].[TABLE_NAME]), [t1].[COLUMN_NAME], 'ColumnID')
) as comment
FROM {$columnsTableName} AS [t1]
LEFT OUTER JOIN [sys].[extended_properties] AS [t2] ON
[t2].[minor_id] = COLUMNPROPERTY(OBJECT_ID([t1].[TABLE_SCHEMA] + '.' + [t1].[TABLE_NAME]), [t1].[COLUMN_NAME], 'ColumnID') AND
OBJECT_NAME([t2].[major_id]) = [t1].[table_name] AND
[t2].[class] = 1 AND
[t2].[class_desc] = 'OBJECT_OR_COLUMN' AND
[t2].[name] = 'MS_Description'
WHERE {$whereSql}
SQL;

Expand Down Expand Up @@ -352,39 +358,38 @@ protected function findPrimaryKeys($table)
*/
protected function findForeignKeys($table)
{
$referentialConstraintsTableName = 'INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS';
$keyColumnUsageTableName = 'INFORMATION_SCHEMA.KEY_COLUMN_USAGE';
$object = $table->name;
if ($table->schemaName !== null) {
$object = $table->schemaName . '.' . $object;
}
if ($table->catalogName !== null) {
$referentialConstraintsTableName = $table->catalogName . '.' . $referentialConstraintsTableName;
$keyColumnUsageTableName = $table->catalogName . '.' . $keyColumnUsageTableName;
$object = $table->catalogName . '.' . $object;
}
$referentialConstraintsTableName = $this->quoteTableName($referentialConstraintsTableName);
$keyColumnUsageTableName = $this->quoteTableName($keyColumnUsageTableName);

// please refer to the following page for more details:
// http://msdn2.microsoft.com/en-us/library/aa175805(SQL.80).aspx
$sql = <<<SQL
SELECT
[rc].[constraint_name] AS [fk_name],
[kcu1].[column_name] AS [fk_column_name],
[kcu2].[table_name] AS [uq_table_name],
[kcu2].[column_name] AS [uq_column_name]
FROM {$referentialConstraintsTableName} AS [rc]
JOIN {$keyColumnUsageTableName} AS [kcu1] ON
[kcu1].[constraint_catalog] = [rc].[constraint_catalog] AND
[kcu1].[constraint_schema] = [rc].[constraint_schema] AND
[kcu1].[constraint_name] = [rc].[constraint_name]
JOIN {$keyColumnUsageTableName} AS [kcu2] ON
[kcu2].[constraint_catalog] = [rc].[constraint_catalog] AND
[kcu2].[constraint_schema] = [rc].[constraint_schema] AND
[kcu2].[constraint_name] = [rc].[unique_constraint_name] AND
[kcu2].[ordinal_position] = [kcu1].[ordinal_position]
WHERE [kcu1].[table_name] = :tableName AND [kcu1].[table_schema] = :schemaName
[fk].[name] AS [fk_name],
[cp].[name] AS [fk_column_name],
OBJECT_NAME([fk].[referenced_object_id]) AS [uq_table_name],
[cr].[name] AS [uq_column_name]
FROM
[sys].[foreign_keys] AS [fk]
INNER JOIN [sys].[foreign_key_columns] AS [fkc] ON
[fk].[object_id] = [fkc].[constraint_object_id]
INNER JOIN [sys].[columns] AS [cp] ON
[fk].[parent_object_id] = [cp].[object_id] AND
[fkc].[parent_column_id] = [cp].[column_id]
INNER JOIN [sys].[columns] AS [cr] ON
[fk].[referenced_object_id] = [cr].[object_id] AND
[fkc].[referenced_column_id] = [cr].[column_id]
WHERE
[fk].[parent_object_id] = OBJECT_ID(:object)
SQL;

$rows = $this->db->createCommand($sql, [
':tableName' => $table->name,
':schemaName' => $table->schemaName,
':object' => $object,
])->queryAll();

$table->foreignKeys = [];
Expand Down

0 comments on commit 2242019

Please sign in to comment.