Issues (21)

src/Schema.php (1 issue)

1
<?php
2
3
declare(strict_types=1);
4
5
namespace Yiisoft\Db\Pgsql;
6
7
use JsonException;
8
use Throwable;
9
use Yiisoft\Db\Constraint\CheckConstraint;
10
use Yiisoft\Db\Constraint\Constraint;
11
use Yiisoft\Db\Constraint\DefaultValueConstraint;
12
use Yiisoft\Db\Constraint\ForeignKeyConstraint;
13
use Yiisoft\Db\Constraint\IndexConstraint;
14
use Yiisoft\Db\Driver\Pdo\AbstractPdoSchema;
15
use Yiisoft\Db\Exception\Exception;
16
use Yiisoft\Db\Exception\InvalidConfigException;
17
use Yiisoft\Db\Exception\NotSupportedException;
18
use Yiisoft\Db\Expression\Expression;
19
use Yiisoft\Db\Helper\DbArrayHelper;
20
use Yiisoft\Db\Schema\Builder\ColumnInterface;
21
use Yiisoft\Db\Schema\ColumnSchemaInterface;
22
use Yiisoft\Db\Schema\TableSchemaInterface;
23
24
use function array_change_key_case;
25
use function array_map;
26
use function array_merge;
27
use function array_unique;
28
use function array_values;
29
use function explode;
30
use function hex2bin;
31
use function is_string;
32
use function preg_match;
33
use function preg_replace;
34
use function str_replace;
35
use function str_starts_with;
36
use function substr;
37
38
/**
39
 * Implements the PostgreSQL Server specific schema, supporting PostgreSQL Server version 9.6 and above.
40
 *
41
 * @psalm-type ColumnArray = array{
42
 *   table_schema: string,
43
 *   table_name: string,
44
 *   column_name: string,
45
 *   data_type: string,
46
 *   type_type: string|null,
47
 *   type_scheme: string|null,
48
 *   character_maximum_length: int,
49
 *   column_comment: string|null,
50
 *   modifier: int,
51
 *   is_nullable: bool,
52
 *   column_default: string|null,
53
 *   is_autoinc: bool,
54
 *   sequence_name: string|null,
55
 *   enum_values: string|null,
56
 *   numeric_precision: int|null,
57
 *   numeric_scale: int|null,
58
 *   size: string|null,
59
 *   is_pkey: bool|null,
60
 *   dimension: int
61
 * }
62
 * @psalm-type ConstraintArray = array<
63
 *   array-key,
64
 *   array {
65
 *     name: string,
66
 *     column_name: string,
67
 *     type: string,
68
 *     foreign_table_schema: string|null,
69
 *     foreign_table_name: string|null,
70
 *     foreign_column_name: string|null,
71
 *     on_update: string,
72
 *     on_delete: string,
73
 *     check_expr: string
74
 *   }
75
 * >
76
 * @psalm-type FindConstraintArray = array{
77
 *   constraint_name: string,
78
 *   column_name: string,
79
 *   foreign_table_name: string,
80
 *   foreign_table_schema: string,
81
 *   foreign_column_name: string,
82
 * }
83
 */
84
final class Schema extends AbstractPdoSchema
85
{
86
    /**
87
     * Define the abstract column type as `bit`.
88
     */
89
    public const TYPE_BIT = 'bit';
90
    /**
91
     * Define the abstract column type as `structured`.
92
     */
93
    public const TYPE_STRUCTURED = 'structured';
94
95
    /**
96
     * The mapping from physical column types (keys) to abstract column types (values).
97
     *
98
     * @link https://www.postgresql.org/docs/current/datatype.html#DATATYPE-TABLE
99
     *
100
     * @var string[]
101
     */
102
    private const TYPE_MAP = [
103
        'bit' => self::TYPE_BIT,
104
        'bit varying' => self::TYPE_BIT,
105
        'varbit' => self::TYPE_BIT,
106
        'bool' => self::TYPE_BOOLEAN,
107
        'boolean' => self::TYPE_BOOLEAN,
108
        'box' => self::TYPE_STRING,
109
        'circle' => self::TYPE_STRING,
110
        'point' => self::TYPE_STRING,
111
        'line' => self::TYPE_STRING,
112
        'lseg' => self::TYPE_STRING,
113
        'polygon' => self::TYPE_STRING,
114
        'path' => self::TYPE_STRING,
115
        'character' => self::TYPE_CHAR,
116
        'char' => self::TYPE_CHAR,
117
        'bpchar' => self::TYPE_CHAR,
118
        'character varying' => self::TYPE_STRING,
119
        'varchar' => self::TYPE_STRING,
120
        'text' => self::TYPE_TEXT,
121
        'bytea' => self::TYPE_BINARY,
122
        'cidr' => self::TYPE_STRING,
123
        'inet' => self::TYPE_STRING,
124
        'macaddr' => self::TYPE_STRING,
125
        'real' => self::TYPE_FLOAT,
126
        'float4' => self::TYPE_FLOAT,
127
        'double precision' => self::TYPE_DOUBLE,
128
        'float8' => self::TYPE_DOUBLE,
129
        'decimal' => self::TYPE_DECIMAL,
130
        'numeric' => self::TYPE_DECIMAL,
131
        'money' => self::TYPE_MONEY,
132
        'smallint' => self::TYPE_SMALLINT,
133
        'int2' => self::TYPE_SMALLINT,
134
        'int4' => self::TYPE_INTEGER,
135
        'int' => self::TYPE_INTEGER,
136
        'integer' => self::TYPE_INTEGER,
137
        'bigint' => self::TYPE_BIGINT,
138
        'int8' => self::TYPE_BIGINT,
139
        'oid' => self::TYPE_BIGINT, // shouldn't be used. it's pg internal!
140
        'smallserial' => self::TYPE_SMALLINT,
141
        'serial2' => self::TYPE_SMALLINT,
142
        'serial4' => self::TYPE_INTEGER,
143
        'serial' => self::TYPE_INTEGER,
144
        'bigserial' => self::TYPE_BIGINT,
145
        'serial8' => self::TYPE_BIGINT,
146
        'pg_lsn' => self::TYPE_BIGINT,
147
        'date' => self::TYPE_DATE,
148
        'interval' => self::TYPE_STRING,
149
        'time without time zone' => self::TYPE_TIME,
150
        'time' => self::TYPE_TIME,
151
        'time with time zone' => self::TYPE_TIME,
152
        'timetz' => self::TYPE_TIME,
153
        'timestamp without time zone' => self::TYPE_TIMESTAMP,
154
        'timestamp' => self::TYPE_TIMESTAMP,
155
        'timestamp with time zone' => self::TYPE_TIMESTAMP,
156
        'timestamptz' => self::TYPE_TIMESTAMP,
157
        'abstime' => self::TYPE_TIMESTAMP,
158
        'tsquery' => self::TYPE_STRING,
159
        'tsvector' => self::TYPE_STRING,
160
        'txid_snapshot' => self::TYPE_STRING,
161
        'unknown' => self::TYPE_STRING,
162
        'uuid' => self::TYPE_STRING,
163
        'json' => self::TYPE_JSON,
164
        'jsonb' => self::TYPE_JSON,
165
        'xml' => self::TYPE_STRING,
166
    ];
167
168
    /**
169
     * @var string|null The default schema used for the current session.
170
     */
171
    protected string|null $defaultSchema = 'public';
172
173
    /**
174
     * @var string|string[] Character used to quote schema, table, etc. names.
175
     *
176
     * An array of 2 characters can be used in case starting and ending characters are different.
177
     */
178
    protected string|array $tableQuoteCharacter = '"';
179
180 14
    public function createColumn(string $type, array|int|string $length = null): ColumnInterface
181
    {
182 14
        return new Column($type, $length);
183
    }
184
185
    /**
186
     * Resolves the table name and schema name (if any).
187
     *
188
     * @param string $name The table name.
189
     *
190
     * @return TableSchemaInterface With resolved table, schema, etc. names.
191
     *
192
     * @see TableSchemaInterface
193
     */
194 245
    protected function resolveTableName(string $name): TableSchemaInterface
195
    {
196 245
        $resolvedName = new TableSchema();
197
198 245
        $parts = array_reverse($this->db->getQuoter()->getTableNameParts($name));
199 245
        $resolvedName->name($parts[0] ?? '');
200 245
        $resolvedName->schemaName($parts[1] ?? $this->defaultSchema);
201
202 245
        $resolvedName->fullName(
203 245
            $resolvedName->getSchemaName() !== $this->defaultSchema ?
204 245
            implode('.', array_reverse($parts)) : $resolvedName->getName()
205 245
        );
206
207 245
        return $resolvedName;
208
    }
209
210
    /**
211
     * Returns all schema names in the database, including the default one but not system schemas.
212
     *
213
     * This method should be overridden by child classes to support this feature because the default implementation
214
     * simply throws an exception.
215
     *
216
     * @throws Exception
217
     * @throws InvalidConfigException
218
     * @throws Throwable
219
     *
220
     * @return array All schemas name in the database, except system schemas.
221
     */
222 1
    protected function findSchemaNames(): array
223
    {
224 1
        $sql = <<<SQL
225
        SELECT "ns"."nspname"
226
        FROM "pg_namespace" AS "ns"
227
        WHERE "ns"."nspname" != 'information_schema' AND "ns"."nspname" NOT LIKE 'pg_%'
228
        ORDER BY "ns"."nspname" ASC
229 1
        SQL;
230
231 1
        return $this->db->createCommand($sql)->queryColumn();
232
    }
233
234
    /**
235
     * @throws Exception
236
     * @throws InvalidConfigException
237
     * @throws Throwable
238
     */
239 189
    protected function findTableComment(TableSchemaInterface $tableSchema): void
240
    {
241 189
        $sql = <<<SQL
242
        SELECT obj_description(pc.oid, 'pg_class')
243
        FROM pg_catalog.pg_class pc
244
        INNER JOIN pg_namespace pn ON pc.relnamespace = pn.oid
245
        WHERE
246
        pc.relname=:tableName AND
247
        pn.nspname=:schemaName
248 189
        SQL;
249
250 189
        $comment = $this->db->createCommand($sql, [
251 189
            ':schemaName' => $tableSchema->getSchemaName(),
252 189
            ':tableName' => $tableSchema->getName(),
253 189
        ])->queryScalar();
254
255 189
        $tableSchema->comment(is_string($comment) ? $comment : null);
256
    }
257
258
    /**
259
     * Returns all table names in the database.
260
     *
261
     * This method should be overridden by child classes to support this feature because the default implementation
262
     * simply throws an exception.
263
     *
264
     * @param string $schema The schema of the tables.
265
     * Defaults to empty string, meaning the current or default schema.
266
     *
267
     * @throws Exception
268
     * @throws InvalidConfigException
269
     * @throws Throwable
270
     *
271
     * @return array All tables name in the database. The names have NO schema name prefix.
272
     */
273 12
    protected function findTableNames(string $schema = ''): array
274
    {
275 12
        if ($schema === '') {
276 11
            $schema = $this->defaultSchema;
277
        }
278
279 12
        $sql = <<<SQL
280
        SELECT c.relname AS table_name
281
        FROM pg_class c
282
        INNER JOIN pg_namespace ns ON ns.oid = c.relnamespace
283
        WHERE ns.nspname = :schemaName AND c.relkind IN ('r','v','m','f', 'p')
284
        ORDER BY c.relname
285 12
        SQL;
286
287 12
        return $this->db->createCommand($sql, [':schemaName' => $schema])->queryColumn();
288
    }
289
290
    /**
291
     * Loads the metadata for the specified table.
292
     *
293
     * @param string $name The table name.
294
     *
295
     * @throws Exception
296
     * @throws InvalidConfigException
297
     * @throws Throwable
298
     *
299
     * @return TableSchemaInterface|null DBMS-dependent table metadata, `null` if the table doesn't exist.
300
     */
301 189
    protected function loadTableSchema(string $name): TableSchemaInterface|null
302
    {
303 189
        $table = $this->resolveTableName($name);
304 189
        $this->findTableComment($table);
305
306 189
        if ($this->findColumns($table)) {
307 167
            $this->findConstraints($table);
308 167
            return $table;
309
        }
310
311 43
        return null;
312
    }
313
314
    /**
315
     * Loads a primary key for the given table.
316
     *
317
     * @param string $tableName The table name.
318
     *
319
     * @throws Exception
320
     * @throws InvalidConfigException
321
     * @throws Throwable
322
     *
323
     * @return Constraint|null Primary key for the given table, `null` if the table has no primary key.
324
     */
325 43
    protected function loadTablePrimaryKey(string $tableName): Constraint|null
326
    {
327 43
        $tablePrimaryKey = $this->loadTableConstraints($tableName, self::PRIMARY_KEY);
328
329 43
        return $tablePrimaryKey instanceof Constraint ? $tablePrimaryKey : null;
330
    }
331
332
    /**
333
     * Loads all foreign keys for the given table.
334
     *
335
     * @param string $tableName The table name.
336
     *
337
     * @throws Exception
338
     * @throws InvalidConfigException
339
     * @throws Throwable
340
     *
341
     * @return array Foreign keys for the given table.
342
     *
343
     * @psaml-return array|ForeignKeyConstraint[]
344
     */
345 8
    protected function loadTableForeignKeys(string $tableName): array
346
    {
347 8
        $tableForeignKeys = $this->loadTableConstraints($tableName, self::FOREIGN_KEYS);
348
349 8
        return is_array($tableForeignKeys) ? $tableForeignKeys : [];
350
    }
351
352
    /**
353
     * Loads all indexes for the given table.
354
     *
355
     * @param string $tableName The table name.
356
     *
357
     * @throws Exception
358
     * @throws InvalidConfigException
359
     * @throws Throwable
360
     *
361
     * @return IndexConstraint[] Indexes for the given table.
362
     */
363 42
    protected function loadTableIndexes(string $tableName): array
364
    {
365 42
        $sql = <<<SQL
366
        SELECT
367
            "ic"."relname" AS "name",
368
            "ia"."attname" AS "column_name",
369
            "i"."indisunique" AS "index_is_unique",
370
            "i"."indisprimary" AS "index_is_primary"
371
        FROM "pg_class" AS "tc"
372
        INNER JOIN "pg_namespace" AS "tcns"
373
            ON "tcns"."oid" = "tc"."relnamespace"
374
        LEFT JOIN pg_rewrite AS rw
375
            ON tc.relkind = 'v' AND rw.ev_class = tc.oid AND rw.rulename = '_RETURN'
376
        INNER JOIN "pg_index" AS "i"
377
            ON "i"."indrelid" = "tc"."oid"
378
                OR rw.ev_action IS NOT NULL
379
                AND (SELECT regexp_matches(
380
                    rw.ev_action,
381
                    '{TARGETENTRY .*? :resorigtbl ' || "i"."indrelid" || ' :resorigcol ' || "i"."indkey"[0] || ' '
382
                )) IS NOT NULL
383
        INNER JOIN "pg_class" AS "ic"
384
            ON "ic"."oid" = "i"."indexrelid"
385
        INNER JOIN "pg_attribute" AS "ia"
386
            ON "ia"."attrelid" = "i"."indexrelid" AND "ia"."attnum" <= cardinality("i"."indoption")
387
        WHERE "tcns"."nspname" = :schemaName AND "tc"."relname" = :tableName
388
        ORDER BY "ia"."attnum" ASC
389 42
        SQL;
390
391 42
        $resolvedName = $this->resolveTableName($tableName);
392 42
        $indexes = $this->db->createCommand($sql, [
393 42
            ':schemaName' => $resolvedName->getSchemaName(),
394 42
            ':tableName' => $resolvedName->getName(),
395 42
        ])->queryAll();
396
397
        /** @psalm-var array[] $indexes */
398 42
        $indexes = array_map('array_change_key_case', $indexes);
399 42
        $indexes = DbArrayHelper::index($indexes, null, ['name']);
400 42
        $result = [];
401
402
        /**
403
         * @psalm-var object|string|null $name
404
         * @psalm-var array<
405
         *   array-key,
406
         *   array{
407
         *     name: string,
408
         *     column_name: string,
409
         *     index_is_unique: bool,
410
         *     index_is_primary: bool
411
         *   }
412
         * > $index
413
         */
414 42
        foreach ($indexes as $name => $index) {
415 39
            $ic = (new IndexConstraint())
416 39
                ->name($name)
417 39
                ->columnNames(DbArrayHelper::getColumn($index, 'column_name'))
418 39
                ->primary($index[0]['index_is_primary'])
419 39
                ->unique($index[0]['index_is_unique']);
420
421 39
            $result[] = $ic;
422
        }
423
424 42
        return $result;
425
    }
426
427
    /**
428
     * Loads all unique constraints for the given table.
429
     *
430
     * @param string $tableName The table name.
431
     *
432
     * @throws Exception
433
     * @throws InvalidConfigException
434
     * @throws Throwable
435
     *
436
     * @return array Unique constraints for the given table.
437
     *
438
     * @psalm-return array|Constraint[]
439
     */
440 17
    protected function loadTableUniques(string $tableName): array
441
    {
442 17
        $tableUniques = $this->loadTableConstraints($tableName, self::UNIQUES);
443
444 17
        return is_array($tableUniques) ? $tableUniques : [];
445
    }
446
447
    /**
448
     * Loads all check constraints for the given table.
449
     *
450
     * @param string $tableName The table name.
451
     *
452
     * @throws Exception
453
     * @throws InvalidConfigException
454
     * @throws Throwable
455
     *
456
     * @return array Check constraints for the given table.
457
     *
458
     * @psaml-return array|CheckConstraint[]
459
     */
460 17
    protected function loadTableChecks(string $tableName): array
461
    {
462 17
        $tableChecks = $this->loadTableConstraints($tableName, self::CHECKS);
463
464 17
        return is_array($tableChecks) ? $tableChecks : [];
465
    }
466
467
    /**
468
     * Loads all default value constraints for the given table.
469
     *
470
     * @param string $tableName The table name.
471
     *
472
     * @throws NotSupportedException
473
     *
474
     * @return DefaultValueConstraint[] Default value constraints for the given table.
475
     */
476 13
    protected function loadTableDefaultValues(string $tableName): array
477
    {
478 13
        throw new NotSupportedException(__METHOD__ . ' is not supported by PostgreSQL.');
479
    }
480
481
    /**
482
     * @throws Exception
483
     * @throws InvalidConfigException
484
     * @throws Throwable
485
     */
486 3
    protected function findViewNames(string $schema = ''): array
487
    {
488 3
        if ($schema === '') {
489 1
            $schema = $this->defaultSchema;
490
        }
491
492 3
        $sql = <<<SQL
493
        SELECT c.relname AS table_name
494
        FROM pg_class c
495
        INNER JOIN pg_namespace ns ON ns.oid = c.relnamespace
496
        WHERE ns.nspname = :schemaName AND (c.relkind = 'v' OR c.relkind = 'm')
497
        ORDER BY c.relname
498 3
        SQL;
499
500 3
        return $this->db->createCommand($sql, [':schemaName' => $schema])->queryColumn();
501
    }
502
503
    /**
504
     * Collects the foreign key column details for the given table.
505
     *
506
     * @param TableSchemaInterface $table The table metadata
507
     *
508
     * @throws Exception
509
     * @throws InvalidConfigException
510
     * @throws Throwable
511
     */
512 167
    protected function findConstraints(TableSchemaInterface $table): void
513
    {
514
        /**
515
         * We need to extract the constraints de hard way since:
516
         * {@see https://www.postgresql.org/message-id/[email protected]}
517
         */
518
519 167
        $sql = <<<SQL
520
        SELECT
521
            ct.conname as constraint_name,
522
            a.attname as column_name,
523
            fc.relname as foreign_table_name,
524
            fns.nspname as foreign_table_schema,
525
            fa.attname as foreign_column_name
526
            FROM
527
            (SELECT ct.conname, ct.conrelid, ct.confrelid, ct.conkey, ct.contype, ct.confkey,
528
                generate_subscripts(ct.conkey, 1) AS s
529
                FROM pg_constraint ct
530
            ) AS ct
531
            inner join pg_class c on c.oid=ct.conrelid
532
            inner join pg_namespace ns on c.relnamespace=ns.oid
533
            inner join pg_attribute a on a.attrelid=ct.conrelid and a.attnum = ct.conkey[ct.s]
534
            left join pg_class fc on fc.oid=ct.confrelid
535
            left join pg_namespace fns on fc.relnamespace=fns.oid
536
            left join pg_attribute fa on fa.attrelid=ct.confrelid and fa.attnum = ct.confkey[ct.s]
537
        WHERE
538
            ct.contype='f'
539
            and c.relname=:tableName
540
            and ns.nspname=:schemaName
541
        ORDER BY
542
            fns.nspname, fc.relname, a.attnum
543 167
        SQL;
544
545
        /** @psalm-var array{array{tableName: string, columns: array}} $constraints */
546 167
        $constraints = [];
547
548
        /** @psalm-var array<FindConstraintArray> $rows */
549 167
        $rows = $this->db->createCommand($sql, [
550 167
            ':schemaName' => $table->getSchemaName(),
551 167
            ':tableName' => $table->getName(),
552 167
        ])->queryAll();
553
554 167
        foreach ($rows as $constraint) {
555
            /** @psalm-var FindConstraintArray $constraint */
556 16
            $constraint = array_change_key_case($constraint);
557
558 16
            if ($constraint['foreign_table_schema'] !== $this->defaultSchema) {
559 3
                $foreignTable = $constraint['foreign_table_schema'] . '.' . $constraint['foreign_table_name'];
560
            } else {
561 16
                $foreignTable = $constraint['foreign_table_name'];
562
            }
563
564 16
            $name = $constraint['constraint_name'];
565
566 16
            if (!isset($constraints[$name])) {
567 16
                $constraints[$name] = [
568 16
                    'tableName' => $foreignTable,
569 16
                    'columns' => [],
570 16
                ];
571
            }
572
573 16
            $constraints[$name]['columns'][$constraint['column_name']] = $constraint['foreign_column_name'];
574
        }
575
576
        /**
577
         * @psalm-var int|string $foreingKeyName.
578
         * @psalm-var array{tableName: string, columns: array} $constraint
579
         */
580 167
        foreach ($constraints as $foreingKeyName => $constraint) {
581 16
            $table->foreignKey(
582 16
                (string) $foreingKeyName,
583 16
                array_merge([$constraint['tableName']], $constraint['columns'])
584 16
            );
585
        }
586
    }
587
588
    /**
589
     * Gets information about given table unique indexes.
590
     *
591
     * @param TableSchemaInterface $table The table metadata.
592
     *
593
     * @throws Exception
594
     * @throws InvalidConfigException
595
     * @throws Throwable
596
     *
597
     * @return array With index and column names.
598
     */
599 1
    protected function getUniqueIndexInformation(TableSchemaInterface $table): array
600
    {
601 1
        $sql = <<<'SQL'
602
        SELECT
603
            i.relname as indexname,
604
            pg_get_indexdef(idx.indexrelid, k + 1, TRUE) AS columnname
605
        FROM (
606
            SELECT *, generate_subscripts(indkey, 1) AS k
607
            FROM pg_index
608
        ) idx
609
        INNER JOIN pg_class i ON i.oid = idx.indexrelid
610
        INNER JOIN pg_class c ON c.oid = idx.indrelid
611
        INNER JOIN pg_namespace ns ON c.relnamespace = ns.oid
612
        WHERE idx.indisprimary = FALSE AND idx.indisunique = TRUE
613
        AND c.relname = :tableName AND ns.nspname = :schemaName
614
        ORDER BY i.relname, k
615 1
        SQL;
616
617 1
        return $this->db->createCommand($sql, [
618 1
            ':schemaName' => $table->getSchemaName(),
619 1
            ':tableName' => $table->getName(),
620 1
        ])->queryAll();
621
    }
622
623
    /**
624
     * Returns all unique indexes for the given table.
625
     *
626
     * Each array element is of the following structure:
627
     *
628
     * ```php
629
     * [
630
     *     'IndexName1' => ['col1' [, ...]],
631
     *     'IndexName2' => ['col2' [, ...]],
632
     * ]
633
     * ```
634
     *
635
     * @param TableSchemaInterface $table The table metadata
636
     *
637
     * @throws Exception
638
     * @throws InvalidConfigException
639
     * @throws Throwable
640
     *
641
     * @return array All unique indexes for the given table.
642
     */
643 1
    public function findUniqueIndexes(TableSchemaInterface $table): array
644
    {
645 1
        $uniqueIndexes = [];
646
647
        /** @psalm-var array{indexname: string, columnname: string} $row */
648 1
        foreach ($this->getUniqueIndexInformation($table) as $row) {
649
            /** @psalm-var array{indexname: string, columnname: string} $row */
650 1
            $row = array_change_key_case($row);
651
652 1
            $column = $row['columnname'];
653
654 1
            if (str_starts_with($column, '"') && str_ends_with($column, '"')) {
655
                /**
656
                 * postgres will quote names that aren't lowercase-only.
657
                 *
658
                 * {@see https://github.com/yiisoft/yii2/issues/10613}
659
                 */
660 1
                $column = substr($column, 1, -1);
661
            }
662
663 1
            $uniqueIndexes[$row['indexname']][] = $column;
664
        }
665
666 1
        return $uniqueIndexes;
667
    }
668
669
    /**
670
     * Collects the metadata of table columns.
671
     *
672
     * @param TableSchemaInterface $table The table metadata.
673
     *
674
     * @throws Exception
675
     * @throws InvalidConfigException
676
     * @throws JsonException
677
     * @throws Throwable
678
     *
679
     * @return bool Whether the table exists in the database.
680
     */
681 189
    protected function findColumns(TableSchemaInterface $table): bool
682
    {
683 189
        $orIdentity = '';
684
685 189
        if (version_compare($this->db->getServerVersion(), '12.0', '>=')) {
686 182
            $orIdentity = 'OR a.attidentity != \'\'';
687
        }
688
689 189
        $sql = <<<SQL
690 189
        SELECT
691
            d.nspname AS table_schema,
692
            c.relname AS table_name,
693
            a.attname AS column_name,
694
            COALESCE(td.typname, tb.typname, t.typname) AS data_type,
695
            COALESCE(td.typtype, tb.typtype, t.typtype) AS type_type,
696
            (SELECT nspname FROM pg_namespace WHERE oid = COALESCE(td.typnamespace, tb.typnamespace, t.typnamespace)) AS type_scheme,
697
            a.attlen AS character_maximum_length,
698
            pg_catalog.col_description(c.oid, a.attnum) AS column_comment,
699
            information_schema._pg_truetypmod(a, t) AS modifier,
700
            NOT (a.attnotnull OR t.typnotnull) AS is_nullable,
701
            COALESCE(t.typdefault, pg_get_expr(ad.adbin, ad.adrelid)) AS column_default,
702 189
            COALESCE(pg_get_expr(ad.adbin, ad.adrelid) ~ 'nextval', false) $orIdentity AS is_autoinc,
703
            pg_get_serial_sequence(quote_ident(d.nspname) || '.' || quote_ident(c.relname), a.attname)
704
            AS sequence_name,
705
            CASE WHEN COALESCE(td.typtype, tb.typtype, t.typtype) = 'e'::char
706
                THEN array_to_string(
707
                    (
708
                        SELECT array_agg(enumlabel)
709
                        FROM pg_enum
710
                        WHERE enumtypid = COALESCE(td.oid, tb.oid, a.atttypid)
711
                    )::varchar[],
712
                ',')
713
                ELSE NULL
714
            END AS enum_values,
715
            information_schema._pg_numeric_precision(
716
                COALESCE(td.oid, tb.oid, a.atttypid),
717
                information_schema._pg_truetypmod(a, t)
718
            ) AS numeric_precision,
719
            information_schema._pg_numeric_scale(
720
                COALESCE(td.oid, tb.oid, a.atttypid),
721
                information_schema._pg_truetypmod(a, t)
722
            ) AS numeric_scale,
723
            information_schema._pg_char_max_length(
724
                COALESCE(td.oid, tb.oid, a.atttypid),
725
                information_schema._pg_truetypmod(a, t)
726
            ) AS size,
727
            ct.oid IS NOT NULL AS is_pkey,
728
            COALESCE(NULLIF(a.attndims, 0), NULLIF(t.typndims, 0), (t.typcategory='A')::int) AS dimension
729
        FROM
730
            pg_class c
731
            LEFT JOIN pg_attribute a ON a.attrelid = c.oid
732
            LEFT JOIN pg_attrdef ad ON a.attrelid = ad.adrelid AND a.attnum = ad.adnum
733
            LEFT JOIN pg_type t ON a.atttypid = t.oid
734
            LEFT JOIN pg_type tb ON (a.attndims > 0 OR t.typcategory='A') AND t.typelem > 0 AND t.typelem = tb.oid
735
                                        OR t.typbasetype > 0 AND t.typbasetype = tb.oid
736
            LEFT JOIN pg_type td ON t.typndims > 0 AND t.typbasetype > 0 AND tb.typelem = td.oid
737
            LEFT JOIN pg_namespace d ON d.oid = c.relnamespace
738
            LEFT JOIN pg_rewrite rw ON c.relkind = 'v' AND rw.ev_class = c.oid AND rw.rulename = '_RETURN'
739
            LEFT JOIN pg_constraint ct ON ct.conrelid = c.oid AND ct.contype = 'p' AND a.attnum = ANY (ct.conkey)
740
                OR rw.ev_action IS NOT NULL AND ct.contype = 'p'
741
                AND (ARRAY(
742
                    SELECT regexp_matches(rw.ev_action, '{TARGETENTRY .*? :resorigtbl (\d+) :resorigcol (\d+) ', 'g')
743
                ))[a.attnum:a.attnum] <@ (ct.conrelid::text || ct.conkey::text[])
744
        WHERE
745
            a.attnum > 0 AND t.typname != '' AND NOT a.attisdropped
746
            AND c.relname = :tableName
747
            AND d.nspname = :schemaName
748
        ORDER BY
749
            a.attnum;
750 189
        SQL;
751
752 189
        $columns = $this->db->createCommand($sql, [
753 189
            ':schemaName' => $table->getSchemaName(),
754 189
            ':tableName' => $table->getName(),
755 189
        ])->queryAll();
756
757 189
        if (empty($columns)) {
758 43
            return false;
759
        }
760
761
        /** @psalm-var ColumnArray $info */
762 167
        foreach ($columns as $info) {
763
            /** @psalm-var ColumnArray $info */
764 167
            $info = array_change_key_case($info);
765
766
            /** @psalm-var ColumnSchema $column */
767 167
            $column = $this->loadColumnSchema($info);
768
769 167
            $table->column($column->getName(), $column);
770
771 167
            if ($column->isPrimaryKey()) {
772 102
                $table->primaryKey($column->getName());
773
774 102
                if ($table->getSequenceName() === null) {
775 102
                    $table->sequenceName($column->getSequenceName());
776
                }
777
            }
778
        }
779
780 167
        return true;
781
    }
782
783
    /**
784
     * Loads the column information into a {@see ColumnSchemaInterface} object.
785
     *
786
     * @psalm-param ColumnArray $info Column information.
787
     *
788
     * @return ColumnSchemaInterface The column schema object.
789
     */
790 167
    protected function loadColumnSchema(array $info): ColumnSchemaInterface
791
    {
792 167
        $column = $this->createColumnSchema($info['column_name']);
793 167
        $column->allowNull($info['is_nullable']);
794 167
        $column->autoIncrement($info['is_autoinc']);
795 167
        $column->comment($info['column_comment']);
796
797 167
        if (!in_array($info['type_scheme'], [$this->defaultSchema, 'pg_catalog'], true)) {
798 1
            $column->dbType($info['type_scheme'] . '.' . $info['data_type']);
799
        } else {
800 167
            $column->dbType($info['data_type']);
801
        }
802
803 167
        $column->enumValues($info['enum_values'] !== null
804 1
            ? explode(',', str_replace(["''"], ["'"], $info['enum_values']))
805 167
            : null);
806 167
        $column->unsigned(false); // has no meaning in PG
807 167
        $column->primaryKey((bool) $info['is_pkey']);
808 167
        $column->precision($info['numeric_precision']);
809 167
        $column->scale($info['numeric_scale']);
810 167
        $column->size($info['size'] === null ? null : (int) $info['size']);
811 167
        $column->dimension($info['dimension']);
812
813
        /**
814
         * pg_get_serial_sequence() doesn't track DEFAULT value change.
815
         * GENERATED BY IDENTITY columns always have a null default value.
816
         */
817 167
        $defaultValue = $info['column_default'];
818
819
        if (
820 167
            $defaultValue !== null
821 167
            && preg_match("/^nextval\('([^']+)/", $defaultValue, $matches) === 1
822
        ) {
823 81
            $column->sequenceName($matches[1]);
824 167
        } elseif ($info['sequence_name'] !== null) {
825 5
            $column->sequenceName($this->resolveTableName($info['sequence_name'])->getFullName());
826
        }
827
828 167
        if ($info['type_type'] === 'c') {
829 5
            $column->type(self::TYPE_STRUCTURED);
830 5
            $structured = $this->resolveTableName((string) $column->getDbType());
831
832 5
            if ($this->findColumns($structured)) {
833 5
                $column->columns($structured->getColumns());
834
            }
835
        } else {
836 167
            $column->type(self::TYPE_MAP[(string) $column->getDbType()] ?? self::TYPE_STRING);
837
        }
838
839 167
        $column->phpType($this->getColumnPhpType($column));
840 167
        $column->defaultValue($this->normalizeDefaultValue($defaultValue, $column));
841
842 167
        if ($column->getType() === self::TYPE_STRUCTURED && $column->getDimension() === 0) {
843
            /** @psalm-var array|null $defaultValue */
844 5
            $defaultValue = $column->getDefaultValue();
845 5
            if (is_array($defaultValue)) {
846 5
                foreach ($column->getColumns() as $structuredColumnName => $structuredColumn) {
847 5
                    $structuredColumn->defaultValue($defaultValue[$structuredColumnName] ?? null);
848
                }
849
            }
850
        }
851
852 167
        return $column;
853
    }
854
855
    /**
856
     * Extracts the PHP type from an abstract DB type.
857
     *
858
     * @param ColumnSchemaInterface $column The column schema information.
859
     *
860
     * @return string The PHP type name.
861
     */
862 167
    protected function getColumnPhpType(ColumnSchemaInterface $column): string
863
    {
864 167
        return match ($column->getType()) {
865 167
            self::TYPE_BIT => self::PHP_TYPE_INTEGER,
866 167
            self::TYPE_STRUCTURED => self::PHP_TYPE_ARRAY,
867 167
            default => parent::getColumnPhpType($column),
868 167
        };
869
    }
870
871
    /**
872
     * Converts column's default value according to {@see ColumnSchema::phpType} after retrieval from the database.
873
     *
874
     * @param string|null $defaultValue The default value retrieved from the database.
875
     * @param ColumnSchemaInterface $column The column schema object.
876
     *
877
     * @return mixed The normalized default value.
878
     */
879 167
    private function normalizeDefaultValue(string|null $defaultValue, ColumnSchemaInterface $column): mixed
880
    {
881
        if (
882 167
            $defaultValue === null
883 128
            || $column->isPrimaryKey()
884 167
            || str_starts_with($defaultValue, 'NULL::')
885
        ) {
886 163
            return null;
887
        }
888
889 99
        if ($column->getType() === self::TYPE_BOOLEAN && in_array($defaultValue, ['true', 'false'], true)) {
890 71
            return $defaultValue === 'true';
891
        }
892
893
        if (
894 98
            in_array($column->getType(), [self::TYPE_TIMESTAMP, self::TYPE_DATE, self::TYPE_TIME], true)
895 98
            && in_array(strtoupper($defaultValue), ['NOW()', 'CURRENT_TIMESTAMP', 'CURRENT_DATE', 'CURRENT_TIME'], true)
896
        ) {
897 39
            return new Expression($defaultValue);
898
        }
899
900 98
        $value = preg_replace("/^B?['(](.*?)[)'](?:::[^:]+)?$/s", '$1', $defaultValue);
901 98
        $value = str_replace("''", "'", $value);
902
903 98
        if ($column->getType() === self::TYPE_BINARY && str_starts_with($value, '\\x')) {
904 39
            return hex2bin(substr($value, 2));
905
        }
906
907 98
        return $column->phpTypecast($value);
908
    }
909
910
    /**
911
     * Loads multiple types of constraints and returns the specified ones.
912
     *
913
     * @param string $tableName The table name.
914
     * @param string $returnType The return type:
915
     * - primaryKey
916
     * - foreignKeys
917
     * - uniques
918
     * - checks
919
     *
920
     * @throws Exception
921
     * @throws InvalidConfigException
922
     * @throws Throwable
923
     *
924
     * @return array|Constraint|null Constraints.
925
     *
926
     * @psalm-return CheckConstraint[]|Constraint[]|ForeignKeyConstraint[]|Constraint|null
927
     */
928 85
    private function loadTableConstraints(string $tableName, string $returnType): array|Constraint|null
929
    {
930 85
        $sql = <<<SQL
931
        SELECT
932
            "c"."conname" AS "name",
933
            "a"."attname" AS "column_name",
934
            "c"."contype" AS "type",
935
            "ftcns"."nspname" AS "foreign_table_schema",
936
            "ftc"."relname" AS "foreign_table_name",
937
            "fa"."attname" AS "foreign_column_name",
938
            "c"."confupdtype" AS "on_update",
939
            "c"."confdeltype" AS "on_delete",
940
            pg_get_constraintdef("c"."oid") AS "check_expr"
941
        FROM "pg_class" AS "tc"
942
        INNER JOIN "pg_namespace" AS "tcns"
943
            ON "tcns"."oid" = "tc"."relnamespace"
944
        INNER JOIN "pg_attribute" AS "a"
945
            ON "a"."attrelid" = "tc"."oid"
946
        LEFT JOIN pg_rewrite AS rw
947
            ON "tc"."relkind" = 'v' AND "rw"."ev_class" = "tc"."oid" AND "rw"."rulename" = '_RETURN'
948
        INNER JOIN "pg_constraint" AS "c"
949
            ON "c"."conrelid" = "tc"."oid" AND "a"."attnum" = ANY ("c"."conkey")
950
                OR "rw"."ev_action" IS NOT NULL AND "c"."conrelid" != 0
951
                AND (ARRAY(
952
                    SELECT regexp_matches("rw"."ev_action", '{TARGETENTRY .*? :resorigtbl (\d+) :resorigcol (\d+) ', 'g')
953
                ))["a"."attnum":"a"."attnum"] <@ ("c"."conrelid"::text || "c"."conkey"::text[])
954
        LEFT JOIN "pg_class" AS "ftc"
955
            ON "ftc"."oid" = "c"."confrelid"
956
        LEFT JOIN "pg_namespace" AS "ftcns"
957
            ON "ftcns"."oid" = "ftc"."relnamespace"
958
        LEFT JOIN "pg_attribute" "fa"
959
            ON "fa"."attrelid" = "c"."confrelid" AND "fa"."attnum" = ANY ("c"."confkey")
960
        WHERE "tcns"."nspname" = :schemaName AND "tc"."relname" = :tableName
961
        ORDER BY "a"."attnum" ASC, "fa"."attnum" ASC
962 85
        SQL;
963
964
        /** @psalm-var string[] $actionTypes */
965 85
        $actionTypes = [
966 85
            'a' => 'NO ACTION',
967 85
            'r' => 'RESTRICT',
968 85
            'c' => 'CASCADE',
969 85
            'n' => 'SET NULL',
970 85
            'd' => 'SET DEFAULT',
971 85
        ];
972
973 85
        $resolvedName = $this->resolveTableName($tableName);
974 85
        $constraints = $this->db->createCommand($sql, [
975 85
            ':schemaName' => $resolvedName->getSchemaName(),
976 85
            ':tableName' => $resolvedName->getName(),
977 85
        ])->queryAll();
978
979
        /** @psalm-var array[][] $constraints */
980 85
        $constraints = array_map('array_change_key_case', $constraints);
981 85
        $constraints = DbArrayHelper::index($constraints, null, ['type', 'name']);
982
983 85
        $result = [
984 85
            self::PRIMARY_KEY => null,
985 85
            self::FOREIGN_KEYS => [],
986 85
            self::UNIQUES => [],
987 85
            self::CHECKS => [],
988 85
        ];
989
990
        /**
991
         * @psalm-var string $type
992
         * @psalm-var array $names
993
         */
994 85
        foreach ($constraints as $type => $names) {
995
            /**
996
             * @psalm-var object|string|null $name
997
             * @psalm-var ConstraintArray $constraint
998
             */
999 85
            foreach ($names as $name => $constraint) {
1000
                switch ($type) {
1001 85
                    case 'p':
1002 60
                        $result[self::PRIMARY_KEY] = (new Constraint())
1003 60
                            ->name($name)
1004 60
                            ->columnNames(DbArrayHelper::getColumn($constraint, 'column_name'));
1005 60
                        break;
1006 75
                    case 'f':
1007 19
                        $onDelete = $actionTypes[$constraint[0]['on_delete']] ?? null;
1008 19
                        $onUpdate = $actionTypes[$constraint[0]['on_update']] ?? null;
1009
1010 19
                        $result[self::FOREIGN_KEYS][] = (new ForeignKeyConstraint())
1011 19
                            ->name($name)
1012 19
                            ->columnNames(array_values(
1013 19
                                array_unique(DbArrayHelper::getColumn($constraint, 'column_name'))
1014 19
                            ))
1015 19
                            ->foreignSchemaName($constraint[0]['foreign_table_schema'])
1016 19
                            ->foreignTableName($constraint[0]['foreign_table_name'])
1017 19
                            ->foreignColumnNames(array_values(
1018 19
                                array_unique(DbArrayHelper::getColumn($constraint, 'foreign_column_name'))
1019 19
                            ))
1020 19
                            ->onDelete($onDelete)
1021 19
                            ->onUpdate($onUpdate);
1022 19
                        break;
1023 62
                    case 'u':
1024 59
                        $result[self::UNIQUES][] = (new Constraint())
1025 59
                            ->name($name)
1026 59
                            ->columnNames(DbArrayHelper::getColumn($constraint, 'column_name'));
1027 59
                        break;
1028 15
                    case 'c':
1029 15
                        $result[self::CHECKS][] = (new CheckConstraint())
1030 15
                            ->name($name)
1031 15
                            ->columnNames(DbArrayHelper::getColumn($constraint, 'column_name'))
1032 15
                            ->expression($constraint[0]['check_expr']);
1033 15
                        break;
1034
                }
1035
            }
1036
        }
1037
1038 85
        foreach ($result as $type => $data) {
1039 85
            $this->setTableMetadata($tableName, $type, $data);
1040
        }
1041
1042 85
        return $result[$returnType];
1043
    }
1044
1045
    /**
1046
     * Creates a column schema for the database.
1047
     *
1048
     * This method may be overridden by child classes to create a DBMS-specific column schema.
1049
     *
1050
     * @param string $name Name of the column.
1051
     *
1052
     * @return ColumnSchema
1053
     */
1054 167
    private function createColumnSchema(string $name): ColumnSchema
1055
    {
1056 167
        return new ColumnSchema($name);
1057
    }
1058
1059
    /**
1060
     * Returns the cache key for the specified table name.
1061
     *
1062
     * @param string $name The table name.
1063
     *
1064
     * @return array The cache key.
1065
     *
1066
     * @psalm-suppress DeprecatedMethod
1067
     */
1068 279
    protected function getCacheKey(string $name): array
1069
    {
1070 279
        return array_merge([self::class], $this->generateCacheKey(), [$this->getRawTableName($name)]);
0 ignored issues
show
Deprecated Code introduced by
The function Yiisoft\Db\Schema\Abstra...hema::getRawTableName() has been deprecated: Use {@see Quoter::getRawTableName()}. Will be removed in version 2.0.0. ( Ignorable by Annotation )

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

1070
        return array_merge([self::class], $this->generateCacheKey(), [/** @scrutinizer ignore-deprecated */ $this->getRawTableName($name)]);

This function has been deprecated. The supplier of the function has supplied an explanatory message.

The explanatory message should give you some clue as to whether and when the function will be removed and what other function to use instead.

Loading history...
1071
    }
1072
1073
    /**
1074
     * Returns the cache tag name.
1075
     *
1076
     * This allows {@see refresh()} to invalidate all cached table schemas.
1077
     *
1078
     * @return string The cache tag name.
1079
     */
1080 247
    protected function getCacheTag(): string
1081
    {
1082 247
        return md5(serialize(array_merge([self::class], $this->generateCacheKey())));
1083
    }
1084
}
1085