Passed
Pull Request — master (#108)
by Sergei
15:14 queued 01:56
created

Schema::createColumnSchema()   A

Complexity

Conditions 1
Paths 1

Size

Total Lines 3
Code Lines 1

Duplication

Lines 0
Ratio 0 %

Code Coverage

Tests 2
CRAP Score 1

Importance

Changes 0
Metric Value
cc 1
eloc 1
nc 1
nop 0
dl 0
loc 3
ccs 2
cts 2
cp 1
crap 1
rs 10
c 0
b 0
f 0
1
<?php
2
3
declare(strict_types=1);
4
5
namespace Yiisoft\Db\Mssql;
6
7
use Throwable;
8
use Yiisoft\Arrays\ArrayHelper;
9
use Yiisoft\Db\Cache\SchemaCache;
10
use Yiisoft\Db\Connection\ConnectionInterface;
11
use Yiisoft\Db\Constraint\CheckConstraint;
12
use Yiisoft\Db\Constraint\Constraint;
13
use Yiisoft\Db\Constraint\DefaultValueConstraint;
14
use Yiisoft\Db\Constraint\ForeignKeyConstraint;
15
use Yiisoft\Db\Constraint\IndexConstraint;
16
use Yiisoft\Db\Exception\Exception;
17
use Yiisoft\Db\Exception\InvalidConfigException;
18
use Yiisoft\Db\Schema\ColumnSchemaBuilder;
19
use Yiisoft\Db\Schema\ColumnSchemaInterface;
20
use Yiisoft\Db\Schema\Schema as AbstractSchema;
21
use Yiisoft\Db\Schema\TableSchemaInterface;
22
23
use function array_change_key_case;
24
use function array_map;
25
use function count;
26
use function explode;
27
use function is_array;
28
use function md5;
29
use function preg_match;
30
use function preg_match_all;
31
use function preg_replace;
32
use function serialize;
33
use function str_contains;
34
use function str_replace;
35
use function strcasecmp;
36
use function stripos;
37
38
/**
39
 * Schema is the class for retrieving metadata from MS SQL Server databases (version 2008 and above).
40
 *
41
 * @psalm-type ColumnArray = array{
42
 *   column_name: string,
43
 *   is_nullable: string,
44
 *   data_type: string,
45
 *   column_default: mixed,
46
 *   is_identity: string,
47
 *   comment: null|string
48
 * }
49
 *
50
 * @psalm-type ConstraintArray = array<
51
 *   array-key,
52
 *   array {
53
 *     name: string,
54
 *     column_name: string,
55
 *     type: string,
56
 *     foreign_table_schema: string|null,
57
 *     foreign_table_name: string|null,
58
 *     foreign_column_name: string|null,
59
 *     on_update: string,
60
 *     on_delete: string,
61
 *     check_expr: string,
62
 *     default_expr: string
63
 *   }
64
 * >
65
 */
66
final class Schema extends AbstractSchema
67
{
68
    public const DEFAULTS = 'defaults';
69
70
    /**
71
     * @var string|null the default schema used for the current session.
72
     */
73
    protected ?string $defaultSchema = 'dbo';
74
75
    /**
76
     * @var array mapping from physical column types (keys) to abstract column types (values)
77
     *
78
     * @psalm-var string[]
79
     */
80
    private array $typeMap = [
81
        /** exact numbers */
82
        'bigint' => self::TYPE_BIGINT,
83
        'numeric' => self::TYPE_DECIMAL,
84
        'bit' => self::TYPE_SMALLINT,
85
        'smallint' => self::TYPE_SMALLINT,
86
        'decimal' => self::TYPE_DECIMAL,
87
        'smallmoney' => self::TYPE_MONEY,
88
        'int' => self::TYPE_INTEGER,
89
        'tinyint' => self::TYPE_TINYINT,
90
        'money' => self::TYPE_MONEY,
91
92
        /** approximate numbers */
93
        'float' => self::TYPE_FLOAT,
94
        'double' => self::TYPE_DOUBLE,
95
        'real' => self::TYPE_FLOAT,
96
97
        /** date and time */
98
        'date' => self::TYPE_DATE,
99
        'datetimeoffset' => self::TYPE_DATETIME,
100
        'datetime2' => self::TYPE_DATETIME,
101
        'smalldatetime' => self::TYPE_DATETIME,
102
        'datetime' => self::TYPE_DATETIME,
103
        'time' => self::TYPE_TIME,
104
105
        /** character strings */
106
        'char' => self::TYPE_CHAR,
107
        'varchar' => self::TYPE_STRING,
108
        'text' => self::TYPE_TEXT,
109
110
        /** unicode character strings */
111
        'nchar' => self::TYPE_CHAR,
112
        'nvarchar' => self::TYPE_STRING,
113
        'ntext' => self::TYPE_TEXT,
114
115
        /** binary strings */
116
        'binary' => self::TYPE_BINARY,
117
        'varbinary' => self::TYPE_BINARY,
118
        'image' => self::TYPE_BINARY,
119
120
        /**
121
         * other data types 'cursor' type cannot be used with tables
122
         */
123
        'timestamp' => self::TYPE_TIMESTAMP,
124
        'hierarchyid' => self::TYPE_STRING,
125
        'uniqueidentifier' => self::TYPE_STRING,
126
        'sql_variant' => self::TYPE_STRING,
127
        'xml' => self::TYPE_STRING,
128
        'table' => self::TYPE_STRING,
129
    ];
130
131 390
    public function __construct(private ConnectionInterface $db, SchemaCache $schemaCache)
132
    {
133 390
        parent::__construct($schemaCache);
134
    }
135
136
    /**
137
     * Resolves the table name and schema name (if any).
138
     *
139
     * @param string $name the table name.
140
     *
141
     * @return TableSchemaInterface resolved table, schema, etc. names.
142
     *
143
     * @todo Review this method and see if it can be simplified @darkdef.
144
     * also see case `wrongBehaviour` in \Yiisoft\Db\TestSupport\TestCommandTrait::batchInsertSqlProviderTrait
145
     */
146 90
    protected function resolveTableName(string $name): TableSchemaInterface
147
    {
148 90
        $resolvedName = new TableSchema();
149 90
        $parts = $this->getTableNameParts($name);
150 90
        $partCount = count($parts);
151
152 90
        if ($partCount === 4) {
153
            /** server name, catalog name, schema name and table name passed - not coverage tests */
154
            $resolvedName->catalogName($parts[1]);
155
            $resolvedName->schemaName($parts[2]);
156
            $resolvedName->name($parts[3]);
157
            $resolvedName->fullName(
158
                (string) $resolvedName->getCatalogName() . '.' .
159
                (string) $resolvedName->getSchemaName() . '.' .
160
                $resolvedName->getName()
161
            );
162 90
        } elseif ($partCount === 3) {
163
            /** catalog name, schema name and table name passed - not coverage tests */
164
            $resolvedName->catalogName($parts[0]);
165
            $resolvedName->schemaName($parts[1]);
166
            $resolvedName->name($parts[2]);
167
            $resolvedName->fullName(
168
                (string) $resolvedName->getCatalogName() . '.' .
169
                (string) $resolvedName->getSchemaName() . '.' .
170
                $resolvedName->getName()
171
            );
172 90
        } elseif ($partCount === 2) {
173
            /** only schema name and table name passed - not coverage tests */
174
            $resolvedName->schemaName($parts[0]);
175
            $resolvedName->name($parts[1]);
176
            $resolvedName->fullName(
177
                (
178
                    $resolvedName->getSchemaName() !== $this->defaultSchema
179
                    ? (string) $resolvedName->getSchemaName() . '.' : ''
180
                ) . $resolvedName->getName()
181
            );
182
        } else {
183
            /** only table name passed */
184 90
            $resolvedName->schemaName($this->defaultSchema);
185 90
            $resolvedName->name($parts[0]);
186 90
            $resolvedName->fullName($resolvedName->getName());
187
        }
188
189 90
        return $resolvedName;
190
    }
191
192
    /**
193
     * Splits full table name into parts.
194
     *
195
     * @param string $name
196
     *
197
     * @return array
198
     *
199
     * @psalm-return string[]
200
     */
201 180
    protected function getTableNameParts(string $name): array
202
    {
203 180
        $parts = [$name];
204
205 180
        preg_match_all('/([^.\[\]]+)|\[([^\[\]]+)]/', $name, $matches);
206
207 180
        if (isset($matches[0]) && !empty($matches[0])) {
208 180
            $parts = $matches[0];
209
        }
210
211
        /** @psalm-var string[] */
212 180
        return str_replace(['[', ']'], '', $parts);
213
    }
214
215
    /**
216
     * Returns all schema names in the database, including the default one but not system schemas.
217
     *
218
     * This method should be overridden by child classes in order to support this feature because the default
219
     * implementation simply throws an exception.
220
     *
221
     * @throws Exception|InvalidConfigException|Throwable
222
     *
223
     * @return array All schema names in the database, except system schemas.
224
     *
225
     * @link https://docs.microsoft.com/en-us/sql/relational-databases/system-catalog-views/sys-database-principals-transact-sql
226
     */
227 1
    protected function findSchemaNames(): array
228
    {
229 1
        $sql = <<<SQL
230
        SELECT [s].[name]
231
        FROM [sys].[schemas] AS [s]
232
        INNER JOIN [sys].[database_principals] AS [p] ON [p].[principal_id] = [s].[principal_id]
233
        WHERE [p].[is_fixed_role] = 0 AND [p].[sid] IS NOT NULL
234
        ORDER BY [s].[name] ASC
235
        SQL;
236
237 1
        return $this->db->createCommand($sql)->queryColumn();
0 ignored issues
show
Bug Best Practice introduced by
The expression return $this->db->create...nd($sql)->queryColumn() could return the type false which is incompatible with the type-hinted return array. Consider adding an additional type-check to rule them out.
Loading history...
238
    }
239
240
    /**
241
     * Returns all table names in the database.
242
     *
243
     * This method should be overridden by child classes in order to support this feature because the default
244
     * implementation simply throws an exception.
245
     *
246
     * @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema.
247
     *
248
     * @throws Exception|InvalidConfigException|Throwable
249
     *
250
     * @return array All table names in the database. The names have NO schema name prefix.
251
     */
252 11
    protected function findTableNames(string $schema = ''): array
253
    {
254 11
        if ($schema === '') {
255 11
            $schema = $this->defaultSchema;
256
        }
257
258 11
        $sql = <<<SQL
259
        SELECT [t].[table_name]
260
        FROM [INFORMATION_SCHEMA].[TABLES] AS [t]
261
        WHERE [t].[table_schema] = :schema AND [t].[table_type] IN ('BASE TABLE', 'VIEW')
262
        ORDER BY [t].[table_name]
263
        SQL;
264
265 11
        $tables = $this->db->createCommand($sql, [':schema' => $schema])->queryColumn();
266
267 11
        return array_map(static fn (string $item): string => '[' . $item . ']', $tables);
0 ignored issues
show
Bug introduced by
It seems like $tables can also be of type false; however, parameter $array of array_map() does only seem to accept array, maybe add an additional type check? ( Ignorable by Annotation )

If this is a false-positive, you can also ignore this issue in your code via the ignore-type  annotation

267
        return array_map(static fn (string $item): string => '[' . $item . ']', /** @scrutinizer ignore-type */ $tables);
Loading history...
268
    }
269
270
    /**
271
     * Loads the metadata for the specified table.
272
     *
273
     * @param string $name table name.
274
     *
275
     * @throws Exception|InvalidConfigException|Throwable
276
     *
277
     * @return TableSchemaInterface|null DBMS-dependent table metadata, `null` if the table does not exist.
278
     */
279 114
    protected function loadTableSchema(string $name): ?TableSchemaInterface
280
    {
281 114
        $table = new TableSchema();
282
283 114
        $this->resolveTableNames($table, $name);
284 114
        $this->findPrimaryKeys($table);
285
286 114
        if ($this->findColumns($table)) {
287 105
            $this->findForeignKeys($table);
288 105
            return $table;
289
        }
290
291 19
        return null;
292
    }
293
294
    /**
295
     * Loads a primary key for the given table.
296
     *
297
     * @param string $tableName table name.
298
     *
299
     * @throws Exception|InvalidConfigException|Throwable
300
     *
301
     * @return Constraint|null The primary key for the given table, `null` if the table has no primary key.
302
     */
303 32
    protected function loadTablePrimaryKey(string $tableName): ?Constraint
304
    {
305
        /** @var mixed */
306 32
        $tablePrimaryKey = $this->loadTableConstraints($tableName, self::PRIMARY_KEY);
307 32
        return $tablePrimaryKey instanceof Constraint ? $tablePrimaryKey : null;
308
    }
309
310
    /**
311
     * Loads all foreign keys for the given table.
312
     *
313
     * @param string $tableName table name.
314
     *
315
     * @throws Exception|InvalidConfigException|Throwable
316
     *
317
     * @return array The foreign keys for the given table.
318
     */
319 5
    protected function loadTableForeignKeys(string $tableName): array
320
    {
321
        /** @var mixed */
322 5
        $tableForeingKeys = $this->loadTableConstraints($tableName, self::FOREIGN_KEYS);
323 5
        return is_array($tableForeingKeys) ? $tableForeingKeys : [];
324
    }
325
326
    /**
327
     * Loads all indexes for the given table.
328
     *
329
     * @param string $tableName table name.
330
     *
331
     * @throws Exception|InvalidConfigException|Throwable
332
     *
333
     * @return array indexes for the given table.
334
     */
335 30
    protected function loadTableIndexes(string $tableName): array
336
    {
337 30
        $sql = <<<SQL
338
        SELECT
339
            [i].[name] AS [name],
340
            [iccol].[name] AS [column_name],
341
            [i].[is_unique] AS [index_is_unique],
342
            [i].[is_primary_key] AS [index_is_primary]
343
        FROM [sys].[indexes] AS [i]
344
        INNER JOIN [sys].[index_columns] AS [ic]
345
            ON [ic].[object_id] = [i].[object_id] AND [ic].[index_id] = [i].[index_id]
346
        INNER JOIN [sys].[columns] AS [iccol]
347
            ON [iccol].[object_id] = [ic].[object_id] AND [iccol].[column_id] = [ic].[column_id]
348
        WHERE [i].[object_id] = OBJECT_ID(:fullName)
349
        ORDER BY [ic].[key_ordinal] ASC
350
        SQL;
351
352 30
        $resolvedName = $this->resolveTableName($tableName);
353 30
        $indexes = $this->db->createCommand($sql, [':fullName' => $resolvedName->getFullName()])->queryAll();
354
355
        /** @psalm-var array[] $indexes */
356 30
        $indexes = $this->normalizeRowKeyCase($indexes, true);
357 30
        $indexes = ArrayHelper::index($indexes, null, 'name');
358
359 30
        $result = [];
360
361
        /**
362
         * @psalm-var array<
363
         *   string,
364
         *   array<
365
         *     array-key,
366
         *     array{array-key, name: string, column_name: string, index_is_unique: string, index_is_primary: string}
367
         *   >
368
         * > $indexes
369
         */
370 30
        foreach ($indexes as $name => $index) {
371 27
            $result[] = (new IndexConstraint())
372 27
                ->primary((bool) $index[0]['index_is_primary'])
373 27
                ->unique((bool) $index[0]['index_is_unique'])
374 27
                ->columnNames(ArrayHelper::getColumn($index, 'column_name'))
375 27
                ->name($name);
376
        }
377
378 30
        return $result;
379
    }
380
381
    /**
382
     * Loads all unique constraints for the given table.
383
     *
384
     * @param string $tableName table name.
385
     *
386
     * @throws Exception|InvalidConfigException|Throwable
387
     *
388
     * @return array The unique constraints for the given table.
389
     */
390 14
    protected function loadTableUniques(string $tableName): array
391
    {
392
        /** @var mixed */
393 14
        $tableUniques = $this->loadTableConstraints($tableName, self::UNIQUES);
394 14
        return is_array($tableUniques) ? $tableUniques : [];
395
    }
396
397
    /**
398
     * Loads all check constraints for the given table.
399
     *
400
     * @param string $tableName table name.
401
     *
402
     * @throws Exception|InvalidConfigException|Throwable
403
     *
404
     * @return array The check constraints for the given table.
405
     */
406 14
    protected function loadTableChecks(string $tableName): array
407
    {
408
        /** @var mixed */
409 14
        $tableCheck = $this->loadTableConstraints($tableName, self::CHECKS);
410 14
        return is_array($tableCheck) ? $tableCheck : [];
411
    }
412
413
    /**
414
     * Loads all default value constraints for the given table.
415
     *
416
     * @param string $tableName table name.
417
     *
418
     * @throws Exception|InvalidConfigException|Throwable
419
     *
420
     * @return array The default value constraints for the given table.
421
     */
422 14
    protected function loadTableDefaultValues(string $tableName): array
423
    {
424
        /** @var mixed */
425 14
        $tableDefault = $this->loadTableConstraints($tableName, self::DEFAULTS);
426 14
        return is_array($tableDefault) ? $tableDefault : [];
427
    }
428
429
    /**
430
     * Creates a column schema for the database.
431
     *
432
     * This method may be overridden by child classes to create a DBMS-specific column schema.
433
     *
434
     * @return ColumnSchema column schema instance.
435
     */
436 105
    protected function createColumnSchema(): ColumnSchema
437
    {
438 105
        return new ColumnSchema();
439
    }
440
441
    /**
442
     * Resolves the table name and schema name (if any).
443
     *
444
     * @param TableSchemaInterface $table the table metadata object.
445
     * @param string $name the table name
446
     *
447
     * @todo Review this method and see if it can be simplified @darkdef.
448
     */
449 114
    protected function resolveTableNames(TableSchemaInterface $table, string $name): void
450
    {
451 114
        $parts = $this->getTableNameParts($name);
452
453 114
        $partCount = count($parts);
454
455 114
        if ($partCount === 4) {
456
            /** server name, catalog name, schema name and table name passed - no coverage tests */
457
            $table->catalogName($parts[1]);
458
            $table->schemaName($parts[2]);
459
            $table->name($parts[3]);
460
            $table->fullName(
461
                (string) $table->getCatalogName() . '.' . (string) $table->getSchemaName() . '.' . $table->getName()
462
            );
463 114
        } elseif ($partCount === 3) {
464
            /** catalog name, schema name and table name passed - no coverage tests */
465
            $table->catalogName($parts[0]);
466
            $table->schemaName($parts[1]);
467
            $table->name($parts[2]);
468
            $table->fullName(
469
                (string) $table->getCatalogName() . '.' . (string) $table->getSchemaName() . '.' . $table->getName()
470
            );
471 114
        } elseif ($partCount === 2) {
472
            /** only schema name and table name passed - no coverage tests */
473 3
            $table->schemaName($parts[0]);
474 3
            $table->name($parts[1]);
475 3
            $table->fullName(
476 3
                $table->getSchemaName() !== $this->defaultSchema
477 3
                ? (string) $table->getSchemaName() . '.' . $table->getName() : $table->getName()
478
            );
479
        } else {
480
            /** only table name passed */
481 111
            $table->schemaName($this->defaultSchema);
482 111
            $table->name($parts[0]);
483 111
            $table->fullName($table->getName());
484
        }
485
    }
486
487
    /**
488
     * Loads the column information into a {@see ColumnSchemaInterface} object.
489
     *
490
     * @psalm-param ColumnArray $info The column information.
491
     *
492
     * @return ColumnSchemaInterface the column schema object.
493
     */
494 105
    protected function loadColumnSchema(array $info): ColumnSchemaInterface
495
    {
496 105
        $column = $this->createColumnSchema();
497
498 105
        $column->name($info['column_name']);
499 105
        $column->allowNull($info['is_nullable'] === 'YES');
500 105
        $column->dbType($info['data_type']);
501 105
        $column->enumValues([]); // mssql has only vague equivalents to enum
502 105
        $column->primaryKey(false); // primary key will be determined in findColumns() method
503 105
        $column->autoIncrement($info['is_identity'] === '1');
504 105
        $column->unsigned(stripos($column->getDbType(), 'unsigned') !== false);
505 105
        $column->comment($info['comment'] ?? '');
506 105
        $column->type(self::TYPE_STRING);
507
508 105
        if (preg_match('/^(\w+)(?:\(([^)]+)\))?/', $column->getDbType(), $matches)) {
509 105
            $type = $matches[1];
510
511 105
            if (isset($this->typeMap[$type])) {
512 105
                $column->type($this->typeMap[$type]);
513
            }
514
515 105
            if (!empty($matches[2])) {
516 88
                $values = explode(',', $matches[2]);
517 88
                $column->precision((int) $values[0]);
518 88
                $column->size((int) $values[0]);
519
520 88
                if (isset($values[1])) {
521
                    $column->scale((int) $values[1]);
522
                }
523
524 88
                if ($column->getSize() === 1 && ($type === 'tinyint' || $type === 'bit')) {
525
                    $column->type(self::TYPE_BOOLEAN);
526 88
                } elseif ($type === 'bit') {
527
                    if ($column->getSize() > 32) {
528
                        $column->type(self::TYPE_BIGINT);
529
                    } elseif ($column->getSize() === 32) {
530
                        $column->type(self::TYPE_INTEGER);
531
                    }
532
                }
533
            }
534
        }
535
536 105
        $column->phpType($this->getColumnPhpType($column));
537
538 105
        if ($info['column_default'] === '(NULL)') {
539 4
            $info['column_default'] = null;
540
        }
541
542 105
        if (!$column->isPrimaryKey() && ($column->getType() !== 'timestamp' || $info['column_default'] !== 'CURRENT_TIMESTAMP')) {
543 105
            $column->defaultValue($column->defaultPhpTypecast($info['column_default']));
544
        }
545
546 105
        return $column;
547
    }
548
549
    /**
550
     * Collects the metadata of table columns.
551
     *
552
     * @param TableSchemaInterface $table the table metadata.
553
     *
554
     * @throws Throwable
555
     *
556
     * @return bool whether the table exists in the database.
557
     */
558 114
    protected function findColumns(TableSchemaInterface $table): bool
559
    {
560 114
        $columnsTableName = 'INFORMATION_SCHEMA.COLUMNS';
561 114
        $whereSql = '[t1].[table_name] = ' . (string) $this->db->getQuoter()->quoteValue($table->getName());
562
563 114
        if ($table->getCatalogName() !== null) {
564
            $columnsTableName = "{$table->getCatalogName()}.$columnsTableName";
565
            $whereSql .= " AND [t1].[table_catalog] = '{$table->getCatalogName()}'";
566
        }
567
568 114
        if ($table->getSchemaName() !== null) {
569 114
            $whereSql .= " AND [t1].[table_schema] = '{$table->getSchemaName()}'";
570
        }
571
572 114
        $columnsTableName = $this->db->getQuoter()->quoteTableName($columnsTableName);
573
574 114
        $sql = <<<SQL
575
        SELECT
576
            [t1].[column_name],
577
            [t1].[is_nullable],
578
        CASE WHEN [t1].[data_type] IN ('char','varchar','nchar','nvarchar','binary','varbinary') THEN
579
        CASE WHEN [t1].[character_maximum_length] = NULL OR [t1].[character_maximum_length] = -1 THEN
580
            [t1].[data_type]
581
        ELSE
582
            [t1].[data_type] + '(' + LTRIM(RTRIM(CONVERT(CHAR,[t1].[character_maximum_length]))) + ')'
583
        END
584
        ELSE
585
            [t1].[data_type]
586
        END AS 'data_type',
587
        [t1].[column_default],
588
        COLUMNPROPERTY(OBJECT_ID([t1].[table_schema] + '.' + [t1].[table_name]), [t1].[column_name], 'IsIdentity') AS is_identity,
589
        (
590
        SELECT CONVERT(VARCHAR, [t2].[value])
591
        FROM [sys].[extended_properties] AS [t2]
592
        WHERE
593
        [t2].[class] = 1 AND
594
        [t2].[class_desc] = 'OBJECT_OR_COLUMN' AND
595
        [t2].[name] = 'MS_Description' AND
596
        [t2].[major_id] = OBJECT_ID([t1].[TABLE_SCHEMA] + '.' + [t1].[table_name]) AND
597
        [t2].[minor_id] = COLUMNPROPERTY(OBJECT_ID([t1].[TABLE_SCHEMA] + '.' + [t1].[TABLE_NAME]), [t1].[COLUMN_NAME], 'ColumnID')
598
        ) as comment
599
        FROM $columnsTableName AS [t1]
600
        WHERE $whereSql
601
        SQL;
602
603
        try {
604
            /** @psalm-var ColumnArray[] */
605 114
            $columns = $this->db->createCommand($sql)->queryAll();
606
607 114
            if (empty($columns)) {
608 114
                return false;
609
            }
610
        } catch (Exception) {
611
            return false;
612
        }
613
614 105
        foreach ($columns as $column) {
615 105
            $column = $this->loadColumnSchema($column);
616 105
            foreach ($table->getPrimaryKey() as $primaryKey) {
617 69
                if (strcasecmp($column->getName(), $primaryKey) === 0) {
618 69
                    $column->primaryKey(true);
619 69
                    break;
620
                }
621
            }
622
623 105
            if ($column->isPrimaryKey() && $column->isAutoIncrement()) {
624 68
                $table->sequenceName('');
625
            }
626
627 105
            $table->columns($column->getName(), $column);
628
        }
629
630 105
        return true;
631
    }
632
633
    /**
634
     * Collects the constraint details for the given table and constraint type.
635
     *
636
     * @param TableSchemaInterface $table
637
     * @param string $type either PRIMARY KEY or UNIQUE.
638
     *
639
     * @throws Exception|InvalidConfigException|Throwable
640
     *
641
     * @return array each entry contains index_name and field_name.
642
     */
643 114
    protected function findTableConstraints(TableSchemaInterface $table, string $type): array
644
    {
645 114
        $keyColumnUsageTableName = 'INFORMATION_SCHEMA.KEY_COLUMN_USAGE';
646 114
        $tableConstraintsTableName = 'INFORMATION_SCHEMA.TABLE_CONSTRAINTS';
647
648 114
        $catalogName = $table->getCatalogName();
649 114
        if ($catalogName !== null) {
650
            $keyColumnUsageTableName = $catalogName . '.' . $keyColumnUsageTableName;
651
            $tableConstraintsTableName = $catalogName . '.' . $tableConstraintsTableName;
652
        }
653
654 114
        $keyColumnUsageTableName = $this->db->getQuoter()->quoteTableName($keyColumnUsageTableName);
655 114
        $tableConstraintsTableName = $this->db->getQuoter()->quoteTableName($tableConstraintsTableName);
656
657 114
        $sql = <<<SQL
658
        SELECT
659
            [kcu].[constraint_name] AS [index_name],
660
            [kcu].[column_name] AS [field_name]
661
        FROM $keyColumnUsageTableName AS [kcu]
662
        LEFT JOIN $tableConstraintsTableName AS [tc] ON
663
            [kcu].[table_schema] = [tc].[table_schema] AND
664
            [kcu].[table_name] = [tc].[table_name] AND
665
            [kcu].[constraint_name] = [tc].[constraint_name]
666
        WHERE
667
            [tc].[constraint_type] = :type AND
668
            [kcu].[table_name] = :tableName AND
669
            [kcu].[table_schema] = :schemaName
670
        SQL;
671
672 114
        return $this->db->createCommand(
673
            $sql,
674
            [
675 114
                ':tableName' => $table->getName(),
676 114
                ':schemaName' => $table->getSchemaName(),
677
                ':type' => $type,
678
            ]
679 114
        )->queryAll();
680
    }
681
682
    /**
683
     * Collects the primary key column details for the given table.
684
     *
685
     * @param TableSchemaInterface $table the table metadata
686
     *
687
     * @throws Exception|InvalidConfigException|Throwable
688
     */
689 114
    protected function findPrimaryKeys(TableSchemaInterface $table): void
690
    {
691
        /** @psalm-var array<array-key, array{index_name: string, field_name: string}> $primaryKeys */
692 114
        $primaryKeys = $this->findTableConstraints($table, 'PRIMARY KEY');
693
694 114
        foreach ($primaryKeys as $row) {
695 69
            $table->primaryKey($row['field_name']);
696
        }
697
    }
698
699
    /**
700
     * Collects the foreign key column details for the given table.
701
     *
702
     * @param TableSchemaInterface $table the table metadata
703
     *
704
     * @throws Exception|InvalidConfigException|Throwable
705
     */
706 105
    protected function findForeignKeys(TableSchemaInterface $table): void
707
    {
708 105
        $catalogName = $table->getCatalogName();
709 105
        $fk = [];
710 105
        $object = $table->getName();
711 105
        $schemaName = $table->getSchemaName();
712
713 105
        if ($schemaName !== null) {
714 105
            $object = $schemaName . '.' . $object;
715
        }
716
717 105
        if ($catalogName !== null) {
718
            $object = $catalogName . '.' . $object;
719
        }
720
721
        /**
722
         * Please refer to the following page for more details:
723
         * {@see http://msdn2.microsoft.com/en-us/library/aa175805(SQL.80).aspx}
724
         */
725 105
        $sql = <<<SQL
726
        SELECT
727
        [fk].[name] AS [fk_name],
728
        [cp].[name] AS [fk_column_name],
729
        OBJECT_NAME([fk].[referenced_object_id]) AS [uq_table_name],
730
        [cr].[name] AS [uq_column_name]
731
        FROM [sys].[foreign_keys] AS [fk]
732
        INNER JOIN [sys].[foreign_key_columns] AS [fkc]
733
            ON [fk].[object_id] = [fkc].[constraint_object_id]
734
        INNER JOIN [sys].[columns] AS [cp]
735
            ON [fk].[parent_object_id] = [cp].[object_id] AND [fkc].[parent_column_id] = [cp].[column_id]
736
        INNER JOIN [sys].[columns] AS [cr]
737
            ON [fk].[referenced_object_id] = [cr].[object_id] AND [fkc].[referenced_column_id] = [cr].[column_id]
738
        WHERE [fk].[parent_object_id] = OBJECT_ID(:object)
739
        SQL;
740
741
        /**
742
         * @psalm-var array<
743
         *   array-key,
744
         *   array{fk_name: string, fk_column_name: string, uq_table_name: string, uq_column_name: string}
745
         * > $rows
746
         */
747 105
        $rows = $this->db->createCommand($sql, [':object' => $object])->queryAll();
748 105
        $table->foreignKeys([]);
749
750 105
        foreach ($rows as $row) {
751 6
            if (!isset($table->getForeignKeys()[$row['fk_name']])) {
752 6
                $fk[$row['fk_name']][] = $row['uq_table_name'];
753 6
                $table->foreignKeys($fk);
754
            }
755
756 6
            $fk[$row['fk_name']][$row['fk_column_name']] = $row['uq_column_name'];
757 6
            $table->foreignKeys($fk);
758
        }
759
    }
760
761
    /**
762
     * @throws Exception|InvalidConfigException|Throwable
763
     */
764 3
    protected function findViewNames(string $schema = ''): array
765
    {
766 3
        if ($schema === '') {
767 1
            $schema = $this->defaultSchema;
768
        }
769
770 3
        $sql = <<<SQL
771
        SELECT [t].[table_name]
772
        FROM [INFORMATION_SCHEMA].[TABLES] AS [t]
773
        WHERE [t].[table_schema] = :schema AND [t].[table_type] = 'VIEW'
774
        ORDER BY [t].[table_name]
775
        SQL;
776
777 3
        $views = $this->db->createCommand($sql, [':schema' => $schema])->queryColumn();
778
779 3
        return array_map(static fn (string $item): string => '[' . $item . ']', $views);
0 ignored issues
show
Bug introduced by
It seems like $views can also be of type false; however, parameter $array of array_map() does only seem to accept array, maybe add an additional type check? ( Ignorable by Annotation )

If this is a false-positive, you can also ignore this issue in your code via the ignore-type  annotation

779
        return array_map(static fn (string $item): string => '[' . $item . ']', /** @scrutinizer ignore-type */ $views);
Loading history...
780
    }
781
782
    /**
783
     * Returns all unique indexes for the given table.
784
     *
785
     * Each array element is of the following structure:
786
     *
787
     * ```php
788
     * [
789
     *     'IndexName1' => ['col1' [, ...]],
790
     *     'IndexName2' => ['col2' [, ...]],
791
     * ]
792
     * ```
793
     *
794
     * @param TableSchemaInterface $table the table metadata.
795
     *
796
     * @throws Exception|InvalidConfigException|Throwable
797
     *
798
     * @return array all unique indexes for the given table.
799
     */
800 1
    public function findUniqueIndexes(TableSchemaInterface $table): array
801
    {
802 1
        $result = [];
803
804
        /** @psalm-var array<array-key, array{index_name: string, field_name: string}> $tableUniqueConstraints */
805 1
        $tableUniqueConstraints = $this->findTableConstraints($table, 'UNIQUE');
806
807 1
        foreach ($tableUniqueConstraints as $row) {
808 1
            $result[$row['index_name']][] = $row['field_name'];
809
        }
810
811 1
        return $result;
812
    }
813
814
    /**
815
     * Loads multiple types of constraints and returns the specified ones.
816
     *
817
     * @param string $tableName table name.
818
     * @param string $returnType return type:
819
     * - primaryKey
820
     * - foreignKeys
821
     * - uniques
822
     * - checks
823
     * - defaults
824
     *
825
     * @throws Exception|InvalidConfigException|Throwable
826
     *
827
     * @return mixed constraints.
828
     */
829 79
    private function loadTableConstraints(string $tableName, string $returnType): mixed
830
    {
831 79
        $sql = <<<SQL
832
        SELECT
833
            [o].[name] AS [name],
834
            COALESCE([ccol].[name], [dcol].[name], [fccol].[name], [kiccol].[name]) AS [column_name],
835
            RTRIM([o].[type]) AS [type],
836
            OBJECT_SCHEMA_NAME([f].[referenced_object_id]) AS [foreign_table_schema],
837
            OBJECT_NAME([f].[referenced_object_id]) AS [foreign_table_name],
838
            [ffccol].[name] AS [foreign_column_name],
839
            [f].[update_referential_action_desc] AS [on_update],
840
            [f].[delete_referential_action_desc] AS [on_delete],
841
            [c].[definition] AS [check_expr],
842
            [d].[definition] AS [default_expr]
843
        FROM (SELECT OBJECT_ID(:fullName) AS [object_id]) AS [t]
844
        INNER JOIN [sys].[objects] AS [o]
845
            ON [o].[parent_object_id] = [t].[object_id] AND [o].[type] IN ('PK', 'UQ', 'C', 'D', 'F')
846
        LEFT JOIN [sys].[check_constraints] AS [c]
847
            ON [c].[object_id] = [o].[object_id]
848
        LEFT JOIN [sys].[columns] AS [ccol]
849
            ON [ccol].[object_id] = [c].[parent_object_id] AND [ccol].[column_id] = [c].[parent_column_id]
850
        LEFT JOIN [sys].[default_constraints] AS [d]
851
            ON [d].[object_id] = [o].[object_id]
852
        LEFT JOIN [sys].[columns] AS [dcol]
853
            ON [dcol].[object_id] = [d].[parent_object_id] AND [dcol].[column_id] = [d].[parent_column_id]
854
        LEFT JOIN [sys].[key_constraints] AS [k]
855
            ON [k].[object_id] = [o].[object_id]
856
        LEFT JOIN [sys].[index_columns] AS [kic]
857
            ON [kic].[object_id] = [k].[parent_object_id] AND [kic].[index_id] = [k].[unique_index_id]
858
        LEFT JOIN [sys].[columns] AS [kiccol]
859
            ON [kiccol].[object_id] = [kic].[object_id] AND [kiccol].[column_id] = [kic].[column_id]
860
        LEFT JOIN [sys].[foreign_keys] AS [f]
861
            ON [f].[object_id] = [o].[object_id]
862
        LEFT JOIN [sys].[foreign_key_columns] AS [fc]
863
            ON [fc].[constraint_object_id] = [o].[object_id]
864
        LEFT JOIN [sys].[columns] AS [fccol]
865
            ON [fccol].[object_id] = [fc].[parent_object_id] AND [fccol].[column_id] = [fc].[parent_column_id]
866
        LEFT JOIN [sys].[columns] AS [ffccol]
867
            ON [ffccol].[object_id] = [fc].[referenced_object_id] AND [ffccol].[column_id] = [fc].[referenced_column_id]
868
        ORDER BY [kic].[key_ordinal] ASC, [fc].[constraint_column_id] ASC
869
        SQL;
870
871 79
        $resolvedName = $this->resolveTableName($tableName);
872 79
        $constraints = $this->db->createCommand($sql, [':fullName' => $resolvedName->getFullName()])->queryAll();
873
874
        /** @psalm-var array[] $constraints */
875 79
        $constraints = $this->normalizeRowKeyCase($constraints, true);
876 79
        $constraints = ArrayHelper::index($constraints, null, ['type', 'name']);
877
878 79
        $result = [
879
            self::PRIMARY_KEY => null,
880 79
            self::FOREIGN_KEYS => [],
881 79
            self::UNIQUES => [],
882 79
            self::CHECKS => [],
883 79
            self::DEFAULTS => [],
884
        ];
885
886
        /** @psalm-var array<array-key, array> $constraints */
887 79
        foreach ($constraints as $type => $names) {
888
            /**
889
             * @psalm-var object|string|null $name
890
             * @psalm-var ConstraintArray $constraint
891
             */
892 79
            foreach ($names as $name => $constraint) {
893 79
                switch ($type) {
894 79
                    case 'PK':
895
                        /** @var Constraint */
896 58
                        $result[self::PRIMARY_KEY] = (new Constraint())
897 58
                            ->columnNames(ArrayHelper::getColumn($constraint, 'column_name'))
898 58
                            ->name($name);
899 58
                        break;
900 79
                    case 'F':
901 21
                        $result[self::FOREIGN_KEYS][] = (new ForeignKeyConstraint())
902 21
                            ->foreignSchemaName($constraint[0]['foreign_table_schema'])
903 21
                            ->foreignTableName($constraint[0]['foreign_table_name'])
904 21
                            ->foreignColumnNames(ArrayHelper::getColumn($constraint, 'foreign_column_name'))
905 21
                            ->onDelete(str_replace('_', '', $constraint[0]['on_delete']))
906 21
                            ->onUpdate(str_replace('_', '', $constraint[0]['on_update']))
907 21
                            ->columnNames(ArrayHelper::getColumn($constraint, 'column_name'))
908 21
                            ->name($name);
909 21
                        break;
910 64
                    case 'UQ':
911 62
                        $result[self::UNIQUES][] = (new Constraint())
912 62
                            ->columnNames(ArrayHelper::getColumn($constraint, 'column_name'))
913 62
                            ->name($name);
914 62
                        break;
915 36
                    case 'C':
916 18
                        $result[self::CHECKS][] = (new CheckConstraint())
917 18
                            ->expression($constraint[0]['check_expr'])
918 18
                            ->columnNames(ArrayHelper::getColumn($constraint, 'column_name'))
919 18
                            ->name($name);
920 18
                        break;
921 35
                    case 'D':
922 35
                        $result[self::DEFAULTS][] = (new DefaultValueConstraint())
923 35
                            ->value($constraint[0]['default_expr'])
924 35
                            ->columnNames(ArrayHelper::getColumn($constraint, 'column_name'))
925 35
                            ->name($name);
926 35
                        break;
927
                }
928
            }
929
        }
930
931 79
        foreach ($result as $type => $data) {
932 79
            $this->setTableMetadata($tableName, $type, $data);
933
        }
934
935 79
        return $result[$returnType];
936
    }
937
938
    /**
939
     * Create a column schema builder instance giving the type and value precision.
940
     *
941
     * This method may be overridden by child classes to create a DBMS-specific column schema builder.
942
     *
943
     * @param string $type type of the column. See {@see ColumnSchemaBuilder::$type}.
944
     * @param array|int|string|null $length length or precision of the column. See {@see ColumnSchemaBuilder::$length}.
945
     *
946
     * @return ColumnSchemaBuilder column schema builder instance
947
     *
948
     * @psalm-param array<array-key, string>|int|null|string $length
949
     */
950 3
    public function createColumnSchemaBuilder(string $type, array|int|string $length = null): ColumnSchemaBuilder
951
    {
952 3
        return new ColumnSchemaBuilder($type, $length);
953
    }
954
955
    /**
956
     * Returns the actual name of a given table name.
957
     *
958
     * This method will strip off curly brackets from the given table name and replace the percentage character '%' with
959
     * {@see ConnectionInterface::tablePrefix}.
960
     *
961
     * @param string $name the table name to be converted.
962
     *
963
     * @return string the real name of the given table name.
964
     */
965 180
    public function getRawTableName(string $name): string
966
    {
967 180
        if (str_contains($name, '{{')) {
968 24
            $name = preg_replace('/{{(.*?)}}/', '\1', $name);
969
970 24
            return str_replace('%', $this->db->getTablePrefix(), $name);
971
        }
972
973 180
        return $name;
974
    }
975
976
    /**
977
     * Returns the cache key for the specified table name.
978
     *
979
     * @param string $name the table name.
980
     *
981
     * @return array the cache key.
982
     */
983 180
    protected function getCacheKey(string $name): array
984
    {
985 180
        return array_merge([__CLASS__], $this->db->getCacheKey(), [$this->getRawTableName($name)]);
986
    }
987
988
    /**
989
     * Returns the cache tag name.
990
     *
991
     * This allows {@see refresh()} to invalidate all cached table schemas.
992
     *
993
     * @return string the cache tag name.
994
     */
995 180
    protected function getCacheTag(): string
996
    {
997 180
        return md5(serialize(array_merge([__CLASS__], $this->db->getCacheKey())));
998
    }
999
1000
    /**
1001
     * @return bool whether this DBMS supports [savepoint](http://en.wikipedia.org/wiki/Savepoint).
1002
     */
1003 5
    public function supportsSavepoint(): bool
1004
    {
1005 5
        return $this->db->isSavepointEnabled();
1006
    }
1007
1008
    /**
1009
     * Changes row's array key case to lower.
1010
     *
1011
     * @param array $row row's array or an array of row's arrays.
1012
     * @param bool $multiple whether multiple rows or a single row passed.
1013
     *
1014
     * @return array normalized row or rows.
1015
     */
1016 90
    protected function normalizeRowKeyCase(array $row, bool $multiple): array
1017
    {
1018 90
        if ($multiple) {
1019 90
            return array_map(static function (array $row) {
1020 87
                return array_change_key_case($row, CASE_LOWER);
1021
            }, $row);
1022
        }
1023
1024
        return array_change_key_case($row, CASE_LOWER);
1025
    }
1026
1027
    /**
1028
     * @inheritDoc
1029
     */
1030
    public function getLastInsertID(?string $sequenceName = null): string
1031
    {
1032
        return $this->db->getLastInsertID($sequenceName);
1033
    }
1034
}
1035