| Total Complexity | 69 |
| Total Lines | 724 |
| Duplicated Lines | 0 % |
| Changes | 0 | ||
Complex classes like Schema often do a lot of different things. To break such a class down, we need to identify a cohesive component within that class. A common approach to find such a component is to look for fields/methods that share the same prefixes, or suffixes.
Once you have determined the fields that belong together, you can apply the Extract Class refactoring. If the component makes sense as a sub-class, Extract Subclass is also a candidate, and is often faster.
While breaking up the class, it is a good idea to analyze how other classes use Schema, and based on these observations, apply Extract Interface, too.
| 1 | <?php |
||
| 23 | class Schema extends \Yiisoft\Db\Schemas\Schema implements ConstraintFinderInterface |
||
| 24 | { |
||
| 25 | use ViewFinderTrait; |
||
| 26 | use ConstraintFinderTrait; |
||
| 27 | |||
| 28 | public const TYPE_JSONB = 'jsonb'; |
||
| 29 | |||
| 30 | /** |
||
| 31 | * @var string the default schema used for the current session. |
||
| 32 | */ |
||
| 33 | public ?string $defaultSchema = 'public'; |
||
| 34 | |||
| 35 | /** |
||
| 36 | * {@inheritdoc} |
||
| 37 | */ |
||
| 38 | public string $columnSchemaClass = ColumnSchema::class; |
||
| 39 | |||
| 40 | /** |
||
| 41 | * @var array mapping from physical column types (keys) to abstract |
||
| 42 | * column types (values) |
||
| 43 | * |
||
| 44 | * {@see http://www.postgresql.org/docs/current/static/datatype.html#DATATYPE-TABLE} |
||
| 45 | */ |
||
| 46 | public array $typeMap = [ |
||
| 47 | 'bit' => self::TYPE_INTEGER, |
||
| 48 | 'bit varying' => self::TYPE_INTEGER, |
||
| 49 | 'varbit' => self::TYPE_INTEGER, |
||
| 50 | 'bool' => self::TYPE_BOOLEAN, |
||
| 51 | 'boolean' => self::TYPE_BOOLEAN, |
||
| 52 | 'box' => self::TYPE_STRING, |
||
| 53 | 'circle' => self::TYPE_STRING, |
||
| 54 | 'point' => self::TYPE_STRING, |
||
| 55 | 'line' => self::TYPE_STRING, |
||
| 56 | 'lseg' => self::TYPE_STRING, |
||
| 57 | 'polygon' => self::TYPE_STRING, |
||
| 58 | 'path' => self::TYPE_STRING, |
||
| 59 | 'character' => self::TYPE_CHAR, |
||
| 60 | 'char' => self::TYPE_CHAR, |
||
| 61 | 'bpchar' => self::TYPE_CHAR, |
||
| 62 | 'character varying' => self::TYPE_STRING, |
||
| 63 | 'varchar' => self::TYPE_STRING, |
||
| 64 | 'text' => self::TYPE_TEXT, |
||
| 65 | 'bytea' => self::TYPE_BINARY, |
||
| 66 | 'cidr' => self::TYPE_STRING, |
||
| 67 | 'inet' => self::TYPE_STRING, |
||
| 68 | 'macaddr' => self::TYPE_STRING, |
||
| 69 | 'real' => self::TYPE_FLOAT, |
||
| 70 | 'float4' => self::TYPE_FLOAT, |
||
| 71 | 'double precision' => self::TYPE_DOUBLE, |
||
| 72 | 'float8' => self::TYPE_DOUBLE, |
||
| 73 | 'decimal' => self::TYPE_DECIMAL, |
||
| 74 | 'numeric' => self::TYPE_DECIMAL, |
||
| 75 | 'money' => self::TYPE_MONEY, |
||
| 76 | 'smallint' => self::TYPE_SMALLINT, |
||
| 77 | 'int2' => self::TYPE_SMALLINT, |
||
| 78 | 'int4' => self::TYPE_INTEGER, |
||
| 79 | 'int' => self::TYPE_INTEGER, |
||
| 80 | 'integer' => self::TYPE_INTEGER, |
||
| 81 | 'bigint' => self::TYPE_BIGINT, |
||
| 82 | 'int8' => self::TYPE_BIGINT, |
||
| 83 | 'oid' => self::TYPE_BIGINT, // should not be used. it's pg internal! |
||
| 84 | 'smallserial' => self::TYPE_SMALLINT, |
||
| 85 | 'serial2' => self::TYPE_SMALLINT, |
||
| 86 | 'serial4' => self::TYPE_INTEGER, |
||
| 87 | 'serial' => self::TYPE_INTEGER, |
||
| 88 | 'bigserial' => self::TYPE_BIGINT, |
||
| 89 | 'serial8' => self::TYPE_BIGINT, |
||
| 90 | 'pg_lsn' => self::TYPE_BIGINT, |
||
| 91 | 'date' => self::TYPE_DATE, |
||
| 92 | 'interval' => self::TYPE_STRING, |
||
| 93 | 'time without time zone' => self::TYPE_TIME, |
||
| 94 | 'time' => self::TYPE_TIME, |
||
| 95 | 'time with time zone' => self::TYPE_TIME, |
||
| 96 | 'timetz' => self::TYPE_TIME, |
||
| 97 | 'timestamp without time zone' => self::TYPE_TIMESTAMP, |
||
| 98 | 'timestamp' => self::TYPE_TIMESTAMP, |
||
| 99 | 'timestamp with time zone' => self::TYPE_TIMESTAMP, |
||
| 100 | 'timestamptz' => self::TYPE_TIMESTAMP, |
||
| 101 | 'abstime' => self::TYPE_TIMESTAMP, |
||
| 102 | 'tsquery' => self::TYPE_STRING, |
||
| 103 | 'tsvector' => self::TYPE_STRING, |
||
| 104 | 'txid_snapshot' => self::TYPE_STRING, |
||
| 105 | 'unknown' => self::TYPE_STRING, |
||
| 106 | 'uuid' => self::TYPE_STRING, |
||
| 107 | 'json' => self::TYPE_JSON, |
||
| 108 | 'jsonb' => self::TYPE_JSON, |
||
| 109 | 'xml' => self::TYPE_STRING, |
||
| 110 | ]; |
||
| 111 | |||
| 112 | /** |
||
| 113 | * {@inheritdoc} |
||
| 114 | */ |
||
| 115 | protected string $tableQuoteCharacter = '"'; |
||
| 116 | |||
| 117 | /** |
||
| 118 | * {@inheritdoc} |
||
| 119 | */ |
||
| 120 | protected function resolveTableName($name) |
||
| 121 | { |
||
| 122 | $resolvedName = new TableSchema(); |
||
| 123 | $parts = \explode('.', \str_replace('"', '', $name)); |
||
| 124 | |||
| 125 | if (isset($parts[1])) { |
||
| 126 | $resolvedName->schemaName = $parts[0]; |
||
| 127 | $resolvedName->name = $parts[1]; |
||
| 128 | } else { |
||
| 129 | $resolvedName->schemaName = $this->defaultSchema; |
||
| 130 | $resolvedName->name = $name; |
||
| 131 | } |
||
| 132 | $resolvedName->fullName = ($resolvedName->schemaName !== $this->defaultSchema ? $resolvedName->schemaName . '.' : '') |
||
| 133 | . $resolvedName->name; |
||
| 134 | return $resolvedName; |
||
| 135 | } |
||
| 136 | |||
| 137 | /** |
||
| 138 | * {@inheritdoc} |
||
| 139 | */ |
||
| 140 | protected function findSchemaNames() |
||
| 141 | { |
||
| 142 | static $sql = <<<'SQL' |
||
| 143 | SELECT "ns"."nspname" |
||
| 144 | FROM "pg_namespace" AS "ns" |
||
| 145 | WHERE "ns"."nspname" != 'information_schema' AND "ns"."nspname" NOT LIKE 'pg_%' |
||
| 146 | ORDER BY "ns"."nspname" ASC |
||
| 147 | SQL; |
||
| 148 | |||
| 149 | return $this->db->createCommand($sql)->queryColumn(); |
||
| 150 | } |
||
| 151 | |||
| 152 | /** |
||
| 153 | * {@inheritdoc} |
||
| 154 | */ |
||
| 155 | protected function findTableNames($schema = '') |
||
| 156 | { |
||
| 157 | if ($schema === '') { |
||
| 158 | $schema = $this->defaultSchema; |
||
| 159 | } |
||
| 160 | $sql = <<<'SQL' |
||
| 161 | SELECT c.relname AS table_name |
||
| 162 | FROM pg_class c |
||
| 163 | INNER JOIN pg_namespace ns ON ns.oid = c.relnamespace |
||
| 164 | WHERE ns.nspname = :schemaName AND c.relkind IN ('r','v','m','f', 'p') |
||
| 165 | ORDER BY c.relname |
||
| 166 | SQL; |
||
| 167 | return $this->db->createCommand($sql, [':schemaName' => $schema])->queryColumn(); |
||
| 168 | } |
||
| 169 | |||
| 170 | /** |
||
| 171 | * {@inheritdoc} |
||
| 172 | */ |
||
| 173 | protected function loadTableSchema($name) |
||
| 174 | { |
||
| 175 | $table = new TableSchema(); |
||
| 176 | $this->resolveTableNames($table, $name); |
||
| 177 | |||
| 178 | if ($this->findColumns($table)) { |
||
| 179 | $this->findConstraints($table); |
||
| 180 | return $table; |
||
| 181 | } |
||
| 182 | |||
| 183 | return null; |
||
| 184 | } |
||
| 185 | |||
| 186 | /** |
||
| 187 | * {@inheritdoc} |
||
| 188 | */ |
||
| 189 | protected function loadTablePrimaryKey($tableName) |
||
| 190 | { |
||
| 191 | return $this->loadTableConstraints($tableName, 'primaryKey'); |
||
| 192 | } |
||
| 193 | |||
| 194 | /** |
||
| 195 | * {@inheritdoc} |
||
| 196 | */ |
||
| 197 | protected function loadTableForeignKeys($tableName) |
||
| 198 | { |
||
| 199 | return $this->loadTableConstraints($tableName, 'foreignKeys'); |
||
| 200 | } |
||
| 201 | |||
| 202 | /** |
||
| 203 | * {@inheritdoc} |
||
| 204 | */ |
||
| 205 | protected function loadTableIndexes($tableName) |
||
| 206 | { |
||
| 207 | static $sql = <<<'SQL' |
||
| 208 | SELECT |
||
| 209 | "ic"."relname" AS "name", |
||
| 210 | "ia"."attname" AS "column_name", |
||
| 211 | "i"."indisunique" AS "index_is_unique", |
||
| 212 | "i"."indisprimary" AS "index_is_primary" |
||
| 213 | FROM "pg_class" AS "tc" |
||
| 214 | INNER JOIN "pg_namespace" AS "tcns" |
||
| 215 | ON "tcns"."oid" = "tc"."relnamespace" |
||
| 216 | INNER JOIN "pg_index" AS "i" |
||
| 217 | ON "i"."indrelid" = "tc"."oid" |
||
| 218 | INNER JOIN "pg_class" AS "ic" |
||
| 219 | ON "ic"."oid" = "i"."indexrelid" |
||
| 220 | INNER JOIN "pg_attribute" AS "ia" |
||
| 221 | ON "ia"."attrelid" = "i"."indrelid" AND "ia"."attnum" = ANY ("i"."indkey") |
||
| 222 | WHERE "tcns"."nspname" = :schemaName AND "tc"."relname" = :tableName |
||
| 223 | ORDER BY "ia"."attnum" ASC |
||
| 224 | SQL; |
||
| 225 | |||
| 226 | $resolvedName = $this->resolveTableName($tableName); |
||
| 227 | |||
| 228 | $indexes = $this->db->createCommand($sql, [ |
||
| 229 | ':schemaName' => $resolvedName->schemaName, |
||
| 230 | ':tableName' => $resolvedName->name, |
||
| 231 | ])->queryAll(); |
||
| 232 | |||
| 233 | $indexes = $this->normalizePdoRowKeyCase($indexes, true); |
||
| 234 | $indexes = ArrayHelper::index($indexes, null, 'name'); |
||
| 235 | $result = []; |
||
| 236 | |||
| 237 | foreach ($indexes as $name => $index) { |
||
| 238 | $ic = new IndexConstraint(); |
||
| 239 | |||
| 240 | $ic->setName($name); |
||
| 241 | $ic->setColumnNames(ArrayHelper::getColumn($index, 'column_name')); |
||
| 242 | $ic->setIsPrimary((bool) $index[0]['index_is_primary']); |
||
| 243 | $ic->setIsUnique((bool) $index[0]['index_is_unique']); |
||
| 244 | |||
| 245 | $result[] = $ic; |
||
| 246 | } |
||
| 247 | |||
| 248 | return $result; |
||
| 249 | } |
||
| 250 | |||
| 251 | /** |
||
| 252 | * {@inheritdoc} |
||
| 253 | */ |
||
| 254 | protected function loadTableUniques($tableName) |
||
| 255 | { |
||
| 256 | return $this->loadTableConstraints($tableName, 'uniques'); |
||
| 257 | } |
||
| 258 | |||
| 259 | /** |
||
| 260 | * {@inheritdoc} |
||
| 261 | */ |
||
| 262 | protected function loadTableChecks($tableName) |
||
| 263 | { |
||
| 264 | return $this->loadTableConstraints($tableName, 'checks'); |
||
| 265 | } |
||
| 266 | |||
| 267 | /** |
||
| 268 | * {@inheritdoc} |
||
| 269 | * |
||
| 270 | * @throws NotSupportedException if this method is called. |
||
| 271 | */ |
||
| 272 | protected function loadTableDefaultValues($tableName) |
||
| 273 | { |
||
| 274 | throw new NotSupportedException('PostgreSQL does not support default value constraints.'); |
||
| 275 | } |
||
| 276 | |||
| 277 | /** |
||
| 278 | * Creates a query builder for the PostgreSQL database. |
||
| 279 | * |
||
| 280 | * @return QueryBuilder query builder instance |
||
| 281 | */ |
||
| 282 | public function createQueryBuilder() |
||
| 283 | { |
||
| 284 | return new QueryBuilder($this->db); |
||
| 285 | } |
||
| 286 | |||
| 287 | /** |
||
| 288 | * Resolves the table name and schema name (if any). |
||
| 289 | * @param TableSchema $table the table metadata object. |
||
| 290 | * |
||
| 291 | * @param string $name the table name |
||
| 292 | */ |
||
| 293 | protected function resolveTableNames($table, $name) |
||
| 294 | { |
||
| 295 | $parts = \explode('.', \str_replace('"', '', $name)); |
||
| 296 | |||
| 297 | if (isset($parts[1])) { |
||
| 298 | $table->schemaName = $parts[0]; |
||
| 299 | $table->name = $parts[1]; |
||
| 300 | } else { |
||
| 301 | $table->schemaName = $this->defaultSchema; |
||
| 302 | $table->name = $parts[0]; |
||
| 303 | } |
||
| 304 | |||
| 305 | $table->fullName = $table->schemaName !== $this->defaultSchema ? $table->schemaName . '.' |
||
| 306 | . $table->name : $table->name; |
||
| 307 | } |
||
| 308 | |||
| 309 | /** |
||
| 310 | * {@inheritdoc] |
||
| 311 | */ |
||
| 312 | protected function findViewNames($schema = '') |
||
| 313 | { |
||
| 314 | if ($schema === '') { |
||
| 315 | $schema = $this->defaultSchema; |
||
| 316 | } |
||
| 317 | $sql = <<<'SQL' |
||
| 318 | SELECT c.relname AS table_name |
||
| 319 | FROM pg_class c |
||
| 320 | INNER JOIN pg_namespace ns ON ns.oid = c.relnamespace |
||
| 321 | WHERE ns.nspname = :schemaName AND (c.relkind = 'v' OR c.relkind = 'm') |
||
| 322 | ORDER BY c.relname |
||
| 323 | SQL; |
||
| 324 | return $this->db->createCommand($sql, [':schemaName' => $schema])->queryColumn(); |
||
| 325 | } |
||
| 326 | |||
| 327 | /** |
||
| 328 | * Collects the foreign key column details for the given table. |
||
| 329 | * |
||
| 330 | * @param TableSchema $table the table metadata |
||
| 331 | */ |
||
| 332 | protected function findConstraints($table) |
||
| 333 | { |
||
| 334 | $tableName = $this->quoteValue($table->name); |
||
| 335 | $tableSchema = $this->quoteValue($table->schemaName); |
||
| 336 | |||
| 337 | //We need to extract the constraints de hard way since: |
||
| 338 | //http://www.postgresql.org/message-id/[email protected] |
||
| 339 | |||
| 340 | $sql = <<<SQL |
||
| 341 | select |
||
| 342 | ct.conname as constraint_name, |
||
| 343 | a.attname as column_name, |
||
| 344 | fc.relname as foreign_table_name, |
||
| 345 | fns.nspname as foreign_table_schema, |
||
| 346 | fa.attname as foreign_column_name |
||
| 347 | from |
||
| 348 | (SELECT ct.conname, ct.conrelid, ct.confrelid, ct.conkey, ct.contype, ct.confkey, generate_subscripts(ct.conkey, 1) AS s |
||
| 349 | FROM pg_constraint ct |
||
| 350 | ) AS ct |
||
| 351 | inner join pg_class c on c.oid=ct.conrelid |
||
| 352 | inner join pg_namespace ns on c.relnamespace=ns.oid |
||
| 353 | inner join pg_attribute a on a.attrelid=ct.conrelid and a.attnum = ct.conkey[ct.s] |
||
| 354 | left join pg_class fc on fc.oid=ct.confrelid |
||
| 355 | left join pg_namespace fns on fc.relnamespace=fns.oid |
||
| 356 | left join pg_attribute fa on fa.attrelid=ct.confrelid and fa.attnum = ct.confkey[ct.s] |
||
| 357 | where |
||
| 358 | ct.contype='f' |
||
| 359 | and c.relname={$tableName} |
||
| 360 | and ns.nspname={$tableSchema} |
||
| 361 | order by |
||
| 362 | fns.nspname, fc.relname, a.attnum |
||
| 363 | SQL; |
||
| 364 | |||
| 365 | $constraints = []; |
||
| 366 | |||
| 367 | foreach ($this->db->createCommand($sql)->queryAll() as $constraint) { |
||
| 368 | if ($this->db->getSlavePdo()->getAttribute(\PDO::ATTR_CASE) === \PDO::CASE_UPPER) { |
||
| 369 | $constraint = \array_change_key_case($constraint, CASE_LOWER); |
||
| 370 | } |
||
| 371 | if ($constraint['foreign_table_schema'] !== $this->defaultSchema) { |
||
| 372 | $foreignTable = $constraint['foreign_table_schema'] . '.' . $constraint['foreign_table_name']; |
||
| 373 | } else { |
||
| 374 | $foreignTable = $constraint['foreign_table_name']; |
||
| 375 | } |
||
| 376 | $name = $constraint['constraint_name']; |
||
| 377 | if (!isset($constraints[$name])) { |
||
| 378 | $constraints[$name] = [ |
||
| 379 | 'tableName' => $foreignTable, |
||
| 380 | 'columns' => [], |
||
| 381 | ]; |
||
| 382 | } |
||
| 383 | $constraints[$name]['columns'][$constraint['column_name']] = $constraint['foreign_column_name']; |
||
| 384 | } |
||
| 385 | |||
| 386 | foreach ($constraints as $name => $constraint) { |
||
| 387 | $table->foreignKeys[$name] = \array_merge([$constraint['tableName']], $constraint['columns']); |
||
| 388 | } |
||
| 389 | } |
||
| 390 | |||
| 391 | /** |
||
| 392 | * Gets information about given table unique indexes. |
||
| 393 | * |
||
| 394 | * @param TableSchema $table the table metadata |
||
| 395 | * |
||
| 396 | * @return array with index and column names |
||
| 397 | */ |
||
| 398 | protected function getUniqueIndexInformation($table) |
||
| 399 | { |
||
| 400 | $sql = <<<'SQL' |
||
| 401 | SELECT |
||
| 402 | i.relname as indexname, |
||
| 403 | pg_get_indexdef(idx.indexrelid, k + 1, TRUE) AS columnname |
||
| 404 | FROM ( |
||
| 405 | SELECT *, generate_subscripts(indkey, 1) AS k |
||
| 406 | FROM pg_index |
||
| 407 | ) idx |
||
| 408 | INNER JOIN pg_class i ON i.oid = idx.indexrelid |
||
| 409 | INNER JOIN pg_class c ON c.oid = idx.indrelid |
||
| 410 | INNER JOIN pg_namespace ns ON c.relnamespace = ns.oid |
||
| 411 | WHERE idx.indisprimary = FALSE AND idx.indisunique = TRUE |
||
| 412 | AND c.relname = :tableName AND ns.nspname = :schemaName |
||
| 413 | ORDER BY i.relname, k |
||
| 414 | SQL; |
||
| 415 | |||
| 416 | return $this->db->createCommand($sql, [ |
||
| 417 | ':schemaName' => $table->schemaName, |
||
| 418 | ':tableName' => $table->name, |
||
| 419 | ])->queryAll(); |
||
| 420 | } |
||
| 421 | |||
| 422 | /** |
||
| 423 | * Returns all unique indexes for the given table. |
||
| 424 | * |
||
| 425 | * Each array element is of the following structure: |
||
| 426 | * |
||
| 427 | * ```php |
||
| 428 | * [ |
||
| 429 | * 'IndexName1' => ['col1' [, ...]], |
||
| 430 | * 'IndexName2' => ['col2' [, ...]], |
||
| 431 | * ] |
||
| 432 | * ``` |
||
| 433 | * |
||
| 434 | * @param TableSchema $table the table metadata |
||
| 435 | * @return array all unique indexes for the given table. |
||
| 436 | */ |
||
| 437 | public function findUniqueIndexes($table) |
||
| 438 | { |
||
| 439 | $uniqueIndexes = []; |
||
| 440 | |||
| 441 | foreach ($this->getUniqueIndexInformation($table) as $row) { |
||
| 442 | if ($this->db->getSlavePdo()->getAttribute(\PDO::ATTR_CASE) === \PDO::CASE_UPPER) { |
||
| 443 | $row = \array_change_key_case($row, CASE_LOWER); |
||
| 444 | } |
||
| 445 | $column = $row['columnname']; |
||
| 446 | if (!empty($column) && $column[0] === '"') { |
||
| 447 | /** |
||
| 448 | * postgres will quote names that are not lowercase-only |
||
| 449 | * https://github.com/yiisoft/yii2/issues/10613 |
||
| 450 | */ |
||
| 451 | $column = \substr($column, 1, -1); |
||
| 452 | } |
||
| 453 | $uniqueIndexes[$row['indexname']][] = $column; |
||
| 454 | } |
||
| 455 | |||
| 456 | return $uniqueIndexes; |
||
| 457 | } |
||
| 458 | |||
| 459 | /** |
||
| 460 | * Collects the metadata of table columns. |
||
| 461 | * |
||
| 462 | * @param TableSchema $table the table metadata |
||
| 463 | * |
||
| 464 | * @return bool whether the table exists in the database |
||
| 465 | */ |
||
| 466 | protected function findColumns($table): bool |
||
| 467 | { |
||
| 468 | $tableName = $this->db->quoteValue($table->name); |
||
| 469 | $schemaName = $this->db->quoteValue($table->schemaName); |
||
| 470 | |||
| 471 | $orIdentity = ''; |
||
| 472 | if (\version_compare($this->db->getServerVersion(), '12.0', '>=')) { |
||
| 473 | $orIdentity = 'OR attidentity != \'\''; |
||
| 474 | } |
||
| 475 | |||
| 476 | $sql = <<<SQL |
||
| 477 | SELECT |
||
| 478 | d.nspname AS table_schema, |
||
| 479 | c.relname AS table_name, |
||
| 480 | a.attname AS column_name, |
||
| 481 | COALESCE(td.typname, tb.typname, t.typname) AS data_type, |
||
| 482 | COALESCE(td.typtype, tb.typtype, t.typtype) AS type_type, |
||
| 483 | a.attlen AS character_maximum_length, |
||
| 484 | pg_catalog.col_description(c.oid, a.attnum) AS column_comment, |
||
| 485 | a.atttypmod AS modifier, |
||
| 486 | a.attnotnull = false AS is_nullable, |
||
| 487 | CAST(pg_get_expr(ad.adbin, ad.adrelid) AS varchar) AS column_default, |
||
| 488 | coalesce(pg_get_expr(ad.adbin, ad.adrelid) ~ 'nextval',false) {$orIdentity} AS is_autoinc, |
||
| 489 | pg_get_serial_sequence(quote_ident(d.nspname) || '.' || quote_ident(c.relname), a.attname) AS sequence_name, |
||
| 490 | CASE WHEN COALESCE(td.typtype, tb.typtype, t.typtype) = 'e'::char |
||
| 491 | THEN array_to_string((SELECT array_agg(enumlabel) FROM pg_enum WHERE enumtypid = COALESCE(td.oid, tb.oid, a.atttypid))::varchar[], ',') |
||
| 492 | ELSE NULL |
||
| 493 | END AS enum_values, |
||
| 494 | CASE atttypid |
||
| 495 | WHEN 21 /*int2*/ THEN 16 |
||
| 496 | WHEN 23 /*int4*/ THEN 32 |
||
| 497 | WHEN 20 /*int8*/ THEN 64 |
||
| 498 | WHEN 1700 /*numeric*/ THEN |
||
| 499 | CASE WHEN atttypmod = -1 |
||
| 500 | THEN null |
||
| 501 | ELSE ((atttypmod - 4) >> 16) & 65535 |
||
| 502 | END |
||
| 503 | WHEN 700 /*float4*/ THEN 24 /*FLT_MANT_DIG*/ |
||
| 504 | WHEN 701 /*float8*/ THEN 53 /*DBL_MANT_DIG*/ |
||
| 505 | ELSE null |
||
| 506 | END AS numeric_precision, |
||
| 507 | CASE |
||
| 508 | WHEN atttypid IN (21, 23, 20) THEN 0 |
||
| 509 | WHEN atttypid IN (1700) THEN |
||
| 510 | CASE |
||
| 511 | WHEN atttypmod = -1 THEN null |
||
| 512 | ELSE (atttypmod - 4) & 65535 |
||
| 513 | END |
||
| 514 | ELSE null |
||
| 515 | END AS numeric_scale, |
||
| 516 | CAST( |
||
| 517 | information_schema._pg_char_max_length(information_schema._pg_truetypid(a, t), information_schema._pg_truetypmod(a, t)) |
||
| 518 | AS numeric |
||
| 519 | ) AS size, |
||
| 520 | a.attnum = any (ct.conkey) as is_pkey, |
||
| 521 | COALESCE(NULLIF(a.attndims, 0), NULLIF(t.typndims, 0), (t.typcategory='A')::int) AS dimension |
||
| 522 | FROM |
||
| 523 | pg_class c |
||
| 524 | LEFT JOIN pg_attribute a ON a.attrelid = c.oid |
||
| 525 | LEFT JOIN pg_attrdef ad ON a.attrelid = ad.adrelid AND a.attnum = ad.adnum |
||
| 526 | LEFT JOIN pg_type t ON a.atttypid = t.oid |
||
| 527 | LEFT JOIN pg_type tb ON (a.attndims > 0 OR t.typcategory='A') AND t.typelem > 0 AND t.typelem = tb.oid OR t.typbasetype > 0 AND t.typbasetype = tb.oid |
||
| 528 | LEFT JOIN pg_type td ON t.typndims > 0 AND t.typbasetype > 0 AND tb.typelem = td.oid |
||
| 529 | LEFT JOIN pg_namespace d ON d.oid = c.relnamespace |
||
| 530 | LEFT JOIN pg_constraint ct ON ct.conrelid = c.oid AND ct.contype = 'p' |
||
| 531 | WHERE |
||
| 532 | a.attnum > 0 AND t.typname != '' AND NOT a.attisdropped |
||
| 533 | AND c.relname = {$tableName} |
||
| 534 | AND d.nspname = {$schemaName} |
||
| 535 | ORDER BY |
||
| 536 | a.attnum; |
||
| 537 | SQL; |
||
| 538 | $columns = $this->db->createCommand($sql)->queryAll(); |
||
| 539 | if (empty($columns)) { |
||
| 540 | return false; |
||
| 541 | } |
||
| 542 | foreach ($columns as $column) { |
||
| 543 | if ($this->db->getSlavePdo()->getAttribute(\PDO::ATTR_CASE) === \PDO::CASE_UPPER) { |
||
| 544 | $column = \array_change_key_case($column, CASE_LOWER); |
||
| 545 | } |
||
| 546 | $column = $this->loadColumnSchema($column); |
||
| 547 | $table->columns[$column->name] = $column; |
||
| 548 | if ($column->isPrimaryKey) { |
||
| 549 | $table->primaryKey[] = $column->name; |
||
| 550 | if ($table->sequenceName === null) { |
||
| 551 | $table->sequenceName = $column->sequenceName; |
||
| 552 | } |
||
| 553 | $column->defaultValue = null; |
||
| 554 | } elseif ($column->defaultValue) { |
||
| 555 | if ($column->type === 'timestamp' && $column->defaultValue === 'now()') { |
||
| 556 | $column->defaultValue = new Expression($column->defaultValue); |
||
| 557 | } elseif ($column->type === 'boolean') { |
||
| 558 | $column->defaultValue = ($column->defaultValue === 'true'); |
||
| 559 | } elseif (\preg_match("/^B'(.*?)'::/", $column->defaultValue, $matches)) { |
||
| 560 | $column->defaultValue = \bindec($matches[1]); |
||
| 561 | } elseif (\strncasecmp($column->dbType, 'bit', 3) === 0 || \strncasecmp($column->dbType, 'varbit', 6) === 0) { |
||
| 562 | $column->defaultValue = \bindec(\trim($column->defaultValue, 'B\'')); |
||
| 563 | } elseif (\preg_match("/^'(.*?)'::/", $column->defaultValue, $matches)) { |
||
| 564 | $column->defaultValue = $column->phpTypecast($matches[1]); |
||
| 565 | } elseif (\preg_match('/^(\()?(.*?)(?(1)\))(?:::.+)?$/', $column->defaultValue, $matches)) { |
||
| 566 | if ($matches[2] === 'NULL') { |
||
| 567 | $column->defaultValue = null; |
||
| 568 | } else { |
||
| 569 | $column->defaultValue = $column->phpTypecast($matches[2]); |
||
| 570 | } |
||
| 571 | } else { |
||
| 572 | $column->defaultValue = $column->phpTypecast($column->defaultValue); |
||
| 573 | } |
||
| 574 | } |
||
| 575 | } |
||
| 576 | |||
| 577 | return true; |
||
| 578 | } |
||
| 579 | |||
| 580 | /** |
||
| 581 | * Loads the column information into a {@see ColumnSchema} object. |
||
| 582 | * |
||
| 583 | * @param array $info column information |
||
| 584 | * |
||
| 585 | * @return ColumnSchema the column schema object |
||
| 586 | */ |
||
| 587 | protected function loadColumnSchema($info): ColumnSchema |
||
| 588 | { |
||
| 589 | /** @var ColumnSchema $column */ |
||
| 590 | $column = $this->createColumnSchema(); |
||
| 591 | $column->allowNull = $info['is_nullable']; |
||
| 592 | $column->autoIncrement = $info['is_autoinc']; |
||
| 593 | $column->comment = $info['column_comment']; |
||
| 594 | $column->dbType = $info['data_type']; |
||
| 595 | $column->defaultValue = $info['column_default']; |
||
| 596 | $column->enumValues = ($info['enum_values'] !== null) ? \explode(',', \str_replace(["''"], ["'"], $info['enum_values'])) : null; |
||
| 597 | $column->unsigned = false; // has no meaning in PG |
||
| 598 | $column->isPrimaryKey = (bool) $info['is_pkey']; |
||
| 599 | $column->name = $info['column_name']; |
||
| 600 | $column->precision = $info['numeric_precision']; |
||
| 601 | $column->scale = $info['numeric_scale']; |
||
| 602 | $column->size = $info['size'] === null ? null : (int) $info['size']; |
||
| 603 | $column->dimension = (int)$info['dimension']; |
||
| 604 | /** |
||
| 605 | * pg_get_serial_sequence() doesn't track DEFAULT value change. GENERATED BY IDENTITY columns always have null |
||
| 606 | * default value |
||
| 607 | */ |
||
| 608 | if (isset($column->defaultValue) && \preg_match("/nextval\\('\"?\\w+\"?\.?\"?\\w+\"?'(::regclass)?\\)/", $column->defaultValue) === 1) { |
||
| 609 | $column->sequenceName = \preg_replace( |
||
| 610 | ['/nextval/', '/::/', '/regclass/', '/\'\)/', '/\(\'/'], |
||
| 611 | '', |
||
| 612 | $column->defaultValue |
||
| 613 | ); |
||
| 614 | } elseif (isset($info['sequence_name'])) { |
||
| 615 | $column->sequenceName = $this->resolveTableName($info['sequence_name'])->fullName; |
||
| 616 | } |
||
| 617 | |||
| 618 | if (isset($this->typeMap[$column->dbType])) { |
||
| 619 | $column->type = $this->typeMap[$column->dbType]; |
||
| 620 | } else { |
||
| 621 | $column->type = self::TYPE_STRING; |
||
| 622 | } |
||
| 623 | $column->phpType = $this->getColumnPhpType($column); |
||
| 624 | |||
| 625 | return $column; |
||
| 626 | } |
||
| 627 | |||
| 628 | /** |
||
| 629 | * {@inheritdoc} |
||
| 630 | */ |
||
| 631 | public function insert($table, $columns) |
||
| 632 | { |
||
| 633 | $params = []; |
||
| 634 | $sql = $this->db->getQueryBuilder()->insert($table, $columns, $params); |
||
| 635 | $returnColumns = $this->getTableSchema($table)->primaryKey; |
||
| 636 | if (!empty($returnColumns)) { |
||
| 637 | $returning = []; |
||
| 638 | foreach ((array) $returnColumns as $name) { |
||
| 639 | $returning[] = $this->quoteColumnName($name); |
||
| 640 | } |
||
| 641 | $sql .= ' RETURNING ' . \implode(', ', $returning); |
||
| 642 | } |
||
| 643 | |||
| 644 | $command = $this->db->createCommand($sql, $params); |
||
| 645 | $command->prepare(false); |
||
| 646 | $result = $command->queryOne(); |
||
| 647 | |||
| 648 | return !$command->pdoStatement->rowCount() ? false : $result; |
||
| 649 | } |
||
| 650 | |||
| 651 | /** |
||
| 652 | * Loads multiple types of constraints and returns the specified ones. |
||
| 653 | * |
||
| 654 | * @param string $tableName table name. |
||
| 655 | * @param string $returnType return type: |
||
| 656 | * - primaryKey |
||
| 657 | * - foreignKeys |
||
| 658 | * - uniques |
||
| 659 | * - checks |
||
| 660 | * |
||
| 661 | * @return mixed constraints. |
||
| 662 | */ |
||
| 663 | private function loadTableConstraints($tableName, $returnType) |
||
| 664 | { |
||
| 665 | static $sql = <<<'SQL' |
||
| 666 | SELECT |
||
| 667 | "c"."conname" AS "name", |
||
| 668 | "a"."attname" AS "column_name", |
||
| 669 | "c"."contype" AS "type", |
||
| 670 | "ftcns"."nspname" AS "foreign_table_schema", |
||
| 671 | "ftc"."relname" AS "foreign_table_name", |
||
| 672 | "fa"."attname" AS "foreign_column_name", |
||
| 673 | "c"."confupdtype" AS "on_update", |
||
| 674 | "c"."confdeltype" AS "on_delete", |
||
| 675 | pg_get_constraintdef("c"."oid") AS "check_expr" |
||
| 676 | FROM "pg_class" AS "tc" |
||
| 677 | INNER JOIN "pg_namespace" AS "tcns" |
||
| 678 | ON "tcns"."oid" = "tc"."relnamespace" |
||
| 679 | INNER JOIN "pg_constraint" AS "c" |
||
| 680 | ON "c"."conrelid" = "tc"."oid" |
||
| 681 | INNER JOIN "pg_attribute" AS "a" |
||
| 682 | ON "a"."attrelid" = "c"."conrelid" AND "a"."attnum" = ANY ("c"."conkey") |
||
| 683 | LEFT JOIN "pg_class" AS "ftc" |
||
| 684 | ON "ftc"."oid" = "c"."confrelid" |
||
| 685 | LEFT JOIN "pg_namespace" AS "ftcns" |
||
| 686 | ON "ftcns"."oid" = "ftc"."relnamespace" |
||
| 687 | LEFT JOIN "pg_attribute" "fa" |
||
| 688 | ON "fa"."attrelid" = "c"."confrelid" AND "fa"."attnum" = ANY ("c"."confkey") |
||
| 689 | WHERE "tcns"."nspname" = :schemaName AND "tc"."relname" = :tableName |
||
| 690 | ORDER BY "a"."attnum" ASC, "fa"."attnum" ASC |
||
| 691 | SQL; |
||
| 692 | static $actionTypes = [ |
||
| 693 | 'a' => 'NO ACTION', |
||
| 694 | 'r' => 'RESTRICT', |
||
| 695 | 'c' => 'CASCADE', |
||
| 696 | 'n' => 'SET NULL', |
||
| 697 | 'd' => 'SET DEFAULT', |
||
| 698 | ]; |
||
| 699 | |||
| 700 | $resolvedName = $this->resolveTableName($tableName); |
||
| 701 | $constraints = $this->db->createCommand($sql, [ |
||
| 702 | ':schemaName' => $resolvedName->schemaName, |
||
| 703 | ':tableName' => $resolvedName->name, |
||
| 704 | ])->queryAll(); |
||
| 705 | $constraints = $this->normalizePdoRowKeyCase($constraints, true); |
||
| 706 | $constraints = ArrayHelper::index($constraints, null, ['type', 'name']); |
||
| 707 | $result = [ |
||
| 708 | 'primaryKey' => null, |
||
| 709 | 'foreignKeys' => [], |
||
| 710 | 'uniques' => [], |
||
| 711 | 'checks' => [], |
||
| 712 | ]; |
||
| 713 | foreach ($constraints as $type => $names) { |
||
| 714 | foreach ($names as $name => $constraint) { |
||
| 715 | switch ($type) { |
||
| 716 | case 'p': |
||
| 717 | $ct = new Constraint(); |
||
| 718 | $ct->setName($name); |
||
| 719 | $ct->setColumnNames(ArrayHelper::getColumn($constraint, 'column_name')); |
||
| 720 | |||
| 721 | $result['primaryKey'] = $ct; |
||
| 722 | break; |
||
| 723 | case 'f': |
||
| 724 | $fk = new ForeignKeyConstraint(); |
||
| 725 | $fk->setName($name); |
||
| 726 | $fk->setColumnNames(\array_values( |
||
| 727 | \array_unique(ArrayHelper::getColumn($constraint, 'column_name')) |
||
| 728 | )); |
||
| 729 | $fk->setForeignColumnNames($constraint[0]['foreign_table_schema']); |
||
| 730 | $fk->setForeignTableName($constraint[0]['foreign_table_name']); |
||
| 731 | $fk->setForeignColumnNames(\array_values( |
||
| 732 | \array_unique(ArrayHelper::getColumn($constraint, 'foreign_column_name')) |
||
| 733 | )); |
||
| 734 | $fk->setOnDelete($actionTypes[$constraint[0]['on_delete']] ?? null); |
||
| 735 | $fk->setOnUpdate($actionTypes[$constraint[0]['on_update']] ?? null); |
||
| 736 | |||
| 737 | $result['foreignKeys'][] = $fk; |
||
| 738 | break; |
||
| 739 | case 'u': |
||
| 740 | $ct = new Constraint(); |
||
| 741 | $ct->setName($name); |
||
| 742 | $ct->setColumnNames(ArrayHelper::getColumn($constraint, 'column_name')); |
||
| 743 | |||
| 744 | $result['uniques'][] = $ct; |
||
| 745 | break; |
||
| 746 | case 'c': |
||
| 747 | $ck = new CheckConstraint(); |
||
| 764 |