-
-
Notifications
You must be signed in to change notification settings - Fork 1.3k
/
MySQLSchemaManager.php
524 lines (433 loc) · 16.5 KB
/
MySQLSchemaManager.php
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
<?php
declare(strict_types=1);
namespace Doctrine\DBAL\Schema;
use Doctrine\DBAL\Exception;
use Doctrine\DBAL\Platforms\AbstractMySQLPlatform;
use Doctrine\DBAL\Platforms\MariaDBPlatform;
use Doctrine\DBAL\Platforms\MySQL;
use Doctrine\DBAL\Platforms\MySQL\CharsetMetadataProvider\CachingCharsetMetadataProvider;
use Doctrine\DBAL\Platforms\MySQL\CharsetMetadataProvider\ConnectionCharsetMetadataProvider;
use Doctrine\DBAL\Platforms\MySQL\CollationMetadataProvider\CachingCollationMetadataProvider;
use Doctrine\DBAL\Platforms\MySQL\CollationMetadataProvider\ConnectionCollationMetadataProvider;
use Doctrine\DBAL\Platforms\MySQL\DefaultTableOptions;
use Doctrine\DBAL\Result;
use Doctrine\DBAL\Types\Type;
use function array_change_key_case;
use function assert;
use function explode;
use function implode;
use function is_string;
use function preg_match;
use function str_contains;
use function strtok;
use function strtolower;
use function strtr;
use const CASE_LOWER;
/**
* Schema manager for the MySQL RDBMS.
*
* @extends AbstractSchemaManager<AbstractMySQLPlatform>
*/
class MySQLSchemaManager extends AbstractSchemaManager
{
/** @see https://mariadb.com/kb/en/library/string-literals/#escape-sequences */
private const MARIADB_ESCAPE_SEQUENCES = [
'\\0' => "\0",
"\\'" => "'",
'\\"' => '"',
'\\b' => "\b",
'\\n' => "\n",
'\\r' => "\r",
'\\t' => "\t",
'\\Z' => "\x1a",
'\\\\' => '\\',
'\\%' => '%',
'\\_' => '_',
// Internally, MariaDB escapes single quotes using the standard syntax
"''" => "'",
];
private ?DefaultTableOptions $defaultTableOptions = null;
/**
* {@inheritDoc}
*/
protected function _getPortableTableDefinition(array $table): string
{
return $table['TABLE_NAME'];
}
/**
* {@inheritDoc}
*/
protected function _getPortableViewDefinition(array $view): View
{
return new View($view['TABLE_NAME'], $view['VIEW_DEFINITION']);
}
/**
* {@inheritDoc}
*/
protected function _getPortableTableIndexesList(array $tableIndexes, string $tableName): array
{
foreach ($tableIndexes as $k => $v) {
$v = array_change_key_case($v, CASE_LOWER);
if ($v['key_name'] === 'PRIMARY') {
$v['primary'] = true;
} else {
$v['primary'] = false;
}
if (str_contains($v['index_type'], 'FULLTEXT')) {
$v['flags'] = ['FULLTEXT'];
} elseif (str_contains($v['index_type'], 'SPATIAL')) {
$v['flags'] = ['SPATIAL'];
}
// Ignore prohibited prefix `length` for spatial index
if (! str_contains($v['index_type'], 'SPATIAL')) {
$v['length'] = isset($v['sub_part']) ? (int) $v['sub_part'] : null;
}
$tableIndexes[$k] = $v;
}
return parent::_getPortableTableIndexesList($tableIndexes, $tableName);
}
/**
* {@inheritDoc}
*/
protected function _getPortableDatabaseDefinition(array $database): string
{
return $database['Database'];
}
/**
* {@inheritDoc}
*/
protected function _getPortableTableColumnDefinition(array $tableColumn): Column
{
$tableColumn = array_change_key_case($tableColumn, CASE_LOWER);
$dbType = strtolower($tableColumn['type']);
$dbType = strtok($dbType, '(), ');
assert(is_string($dbType));
$length = $tableColumn['length'] ?? strtok('(), ');
$fixed = false;
if (! isset($tableColumn['name'])) {
$tableColumn['name'] = '';
}
$scale = 0;
$precision = null;
$type = $this->platform->getDoctrineTypeMapping($dbType);
switch ($dbType) {
case 'char':
case 'binary':
$fixed = true;
break;
case 'float':
case 'double':
case 'real':
case 'numeric':
case 'decimal':
if (
preg_match(
'([A-Za-z]+\(([0-9]+),([0-9]+)\))',
$tableColumn['type'],
$match,
) === 1
) {
$precision = (int) $match[1];
$scale = (int) $match[2];
$length = null;
}
break;
case 'tinytext':
$length = AbstractMySQLPlatform::LENGTH_LIMIT_TINYTEXT;
break;
case 'text':
$length = AbstractMySQLPlatform::LENGTH_LIMIT_TEXT;
break;
case 'mediumtext':
$length = AbstractMySQLPlatform::LENGTH_LIMIT_MEDIUMTEXT;
break;
case 'tinyblob':
$length = AbstractMySQLPlatform::LENGTH_LIMIT_TINYBLOB;
break;
case 'blob':
$length = AbstractMySQLPlatform::LENGTH_LIMIT_BLOB;
break;
case 'mediumblob':
$length = AbstractMySQLPlatform::LENGTH_LIMIT_MEDIUMBLOB;
break;
case 'tinyint':
case 'smallint':
case 'mediumint':
case 'int':
case 'integer':
case 'bigint':
case 'year':
$length = null;
break;
}
if ($this->platform instanceof MariaDBPlatform) {
$columnDefault = $this->getMariaDBColumnDefault($this->platform, $tableColumn['default']);
} else {
$columnDefault = $tableColumn['default'];
}
$options = [
'length' => $length !== null ? (int) $length : null,
'unsigned' => str_contains($tableColumn['type'], 'unsigned'),
'fixed' => $fixed,
'default' => $columnDefault,
'notnull' => $tableColumn['null'] !== 'YES',
'scale' => $scale,
'precision' => $precision,
'autoincrement' => str_contains($tableColumn['extra'], 'auto_increment'),
];
if (isset($tableColumn['comment'])) {
$options['comment'] = $tableColumn['comment'];
}
$column = new Column($tableColumn['field'], Type::getType($type), $options);
if (isset($tableColumn['characterset'])) {
$column->setPlatformOption('charset', $tableColumn['characterset']);
}
if (isset($tableColumn['collation'])) {
$column->setPlatformOption('collation', $tableColumn['collation']);
}
return $column;
}
/**
* Return Doctrine/Mysql-compatible column default values for MariaDB 10.2.7+ servers.
*
* - Since MariaDb 10.2.7 column defaults stored in information_schema are now quoted
* to distinguish them from expressions (see MDEV-10134).
* - CURRENT_TIMESTAMP, CURRENT_TIME, CURRENT_DATE are stored in information_schema
* as current_timestamp(), currdate(), currtime()
* - Quoted 'NULL' is not enforced by Maria, it is technically possible to have
* null in some circumstances (see https://jira.mariadb.org/browse/MDEV-14053)
* - \' is always stored as '' in information_schema (normalized)
*
* @link https://mariadb.com/kb/en/library/information-schema-columns-table/
* @link https://jira.mariadb.org/browse/MDEV-13132
*
* @param string|null $columnDefault default value as stored in information_schema for MariaDB >= 10.2.7
*/
private function getMariaDBColumnDefault(MariaDBPlatform $platform, ?string $columnDefault): ?string
{
if ($columnDefault === 'NULL' || $columnDefault === null) {
return null;
}
if (preg_match('/^\'(.*)\'$/', $columnDefault, $matches) === 1) {
return strtr($matches[1], self::MARIADB_ESCAPE_SEQUENCES);
}
return match ($columnDefault) {
'current_timestamp()' => $platform->getCurrentTimestampSQL(),
'curdate()' => $platform->getCurrentDateSQL(),
'curtime()' => $platform->getCurrentTimeSQL(),
default => $columnDefault,
};
}
/**
* {@inheritDoc}
*/
protected function _getPortableTableForeignKeysList(array $tableForeignKeys): array
{
$list = [];
foreach ($tableForeignKeys as $value) {
$value = array_change_key_case($value, CASE_LOWER);
if (! isset($list[$value['constraint_name']])) {
if (! isset($value['delete_rule']) || $value['delete_rule'] === 'RESTRICT') {
$value['delete_rule'] = null;
}
if (! isset($value['update_rule']) || $value['update_rule'] === 'RESTRICT') {
$value['update_rule'] = null;
}
$list[$value['constraint_name']] = [
'name' => $value['constraint_name'],
'local' => [],
'foreign' => [],
'foreignTable' => $value['referenced_table_name'],
'onDelete' => $value['delete_rule'],
'onUpdate' => $value['update_rule'],
];
}
$list[$value['constraint_name']]['local'][] = $value['column_name'];
$list[$value['constraint_name']]['foreign'][] = $value['referenced_column_name'];
}
return parent::_getPortableTableForeignKeysList($list);
}
/**
* {@inheritDoc}
*/
protected function _getPortableTableForeignKeyDefinition(array $tableForeignKey): ForeignKeyConstraint
{
return new ForeignKeyConstraint(
$tableForeignKey['local'],
$tableForeignKey['foreignTable'],
$tableForeignKey['foreign'],
$tableForeignKey['name'],
[
'onDelete' => $tableForeignKey['onDelete'],
'onUpdate' => $tableForeignKey['onUpdate'],
],
);
}
/** @throws Exception */
public function createComparator(): Comparator
{
return new MySQL\Comparator(
$this->platform,
new CachingCharsetMetadataProvider(
new ConnectionCharsetMetadataProvider($this->connection),
),
new CachingCollationMetadataProvider(
new ConnectionCollationMetadataProvider($this->connection),
),
$this->getDefaultTableOptions(),
);
}
protected function selectTableNames(string $databaseName): Result
{
$sql = <<<'SQL'
SELECT TABLE_NAME
FROM information_schema.TABLES
WHERE TABLE_SCHEMA = ?
AND TABLE_TYPE = 'BASE TABLE'
ORDER BY TABLE_NAME
SQL;
return $this->connection->executeQuery($sql, [$databaseName]);
}
protected function selectTableColumns(string $databaseName, ?string $tableName = null): Result
{
$columnTypeSQL = $this->platform->getColumnTypeSQLSnippet('c', $databaseName);
$sql = 'SELECT';
if ($tableName === null) {
$sql .= ' c.TABLE_NAME,';
}
$sql .= <<<SQL
c.COLUMN_NAME AS field,
$columnTypeSQL AS type,
c.IS_NULLABLE AS `null`,
c.COLUMN_KEY AS `key`,
c.COLUMN_DEFAULT AS `default`,
c.EXTRA,
c.COLUMN_COMMENT AS comment,
c.CHARACTER_SET_NAME AS characterset,
c.COLLATION_NAME AS collation
FROM information_schema.COLUMNS c
INNER JOIN information_schema.TABLES t
ON t.TABLE_NAME = c.TABLE_NAME
SQL;
// The schema name is passed multiple times as a literal in the WHERE clause instead of using a JOIN condition
// in order to avoid performance issues on MySQL older than 8.0 and the corresponding MariaDB versions
// caused by https://bugs.mysql.com/bug.php?id=81347
$conditions = ['c.TABLE_SCHEMA = ?', 't.TABLE_SCHEMA = ?', "t.TABLE_TYPE = 'BASE TABLE'"];
$params = [$databaseName, $databaseName];
if ($tableName !== null) {
$conditions[] = 't.TABLE_NAME = ?';
$params[] = $tableName;
}
$sql .= ' WHERE ' . implode(' AND ', $conditions) . ' ORDER BY ORDINAL_POSITION';
return $this->connection->executeQuery($sql, $params);
}
protected function selectIndexColumns(string $databaseName, ?string $tableName = null): Result
{
$sql = 'SELECT';
if ($tableName === null) {
$sql .= ' TABLE_NAME,';
}
$sql .= <<<'SQL'
NON_UNIQUE AS Non_Unique,
INDEX_NAME AS Key_name,
COLUMN_NAME AS Column_Name,
SUB_PART AS Sub_Part,
INDEX_TYPE AS Index_Type
FROM information_schema.STATISTICS
SQL;
$conditions = ['TABLE_SCHEMA = ?'];
$params = [$databaseName];
if ($tableName !== null) {
$conditions[] = 'TABLE_NAME = ?';
$params[] = $tableName;
}
$sql .= ' WHERE ' . implode(' AND ', $conditions) . ' ORDER BY SEQ_IN_INDEX';
return $this->connection->executeQuery($sql, $params);
}
protected function selectForeignKeyColumns(string $databaseName, ?string $tableName = null): Result
{
$sql = 'SELECT DISTINCT';
if ($tableName === null) {
$sql .= ' k.TABLE_NAME,';
}
$sql .= <<<'SQL'
k.CONSTRAINT_NAME,
k.COLUMN_NAME,
k.REFERENCED_TABLE_NAME,
k.REFERENCED_COLUMN_NAME,
k.ORDINAL_POSITION,
c.UPDATE_RULE,
c.DELETE_RULE
FROM information_schema.key_column_usage k
INNER JOIN information_schema.referential_constraints c
ON c.CONSTRAINT_NAME = k.CONSTRAINT_NAME
AND c.TABLE_NAME = k.TABLE_NAME
SQL;
$conditions = ['k.TABLE_SCHEMA = ?'];
$params = [$databaseName];
if ($tableName !== null) {
$conditions[] = 'k.TABLE_NAME = ?';
$params[] = $tableName;
}
// The schema name is passed multiple times in the WHERE clause instead of using a JOIN condition
// in order to avoid performance issues on MySQL older than 8.0 and the corresponding MariaDB versions
// caused by https://bugs.mysql.com/bug.php?id=81347
$conditions[] = 'c.CONSTRAINT_SCHEMA = ?';
$params[] = $databaseName;
$conditions[] = 'k.REFERENCED_COLUMN_NAME IS NOT NULL';
$sql .= ' WHERE ' . implode(' AND ', $conditions) . ' ORDER BY k.ORDINAL_POSITION';
return $this->connection->executeQuery($sql, $params);
}
/**
* {@inheritDoc}
*/
protected function fetchTableOptionsByTable(string $databaseName, ?string $tableName = null): array
{
$sql = $this->platform->fetchTableOptionsByTable($tableName !== null);
$params = [$databaseName];
if ($tableName !== null) {
$params[] = $tableName;
}
/** @var array<string,array<string,mixed>> $metadata */
$metadata = $this->connection->executeQuery($sql, $params)
->fetchAllAssociativeIndexed();
$tableOptions = [];
foreach ($metadata as $table => $data) {
$data = array_change_key_case($data, CASE_LOWER);
$tableOptions[$table] = [
'engine' => $data['engine'],
'collation' => $data['table_collation'],
'charset' => $data['character_set_name'],
'autoincrement' => $data['auto_increment'],
'comment' => $data['table_comment'],
'create_options' => $this->parseCreateOptions($data['create_options']),
];
}
return $tableOptions;
}
/** @return array<string, string>|array<string, true> */
private function parseCreateOptions(?string $string): array
{
$options = [];
if ($string === null || $string === '') {
return $options;
}
foreach (explode(' ', $string) as $pair) {
$parts = explode('=', $pair, 2);
$options[$parts[0]] = $parts[1] ?? true;
}
return $options;
}
/** @throws Exception */
private function getDefaultTableOptions(): DefaultTableOptions
{
if ($this->defaultTableOptions === null) {
$row = $this->connection->fetchNumeric(
'SELECT @@character_set_database, @@collation_database',
);
assert($row !== false);
$this->defaultTableOptions = new DefaultTableOptions(...$row);
}
return $this->defaultTableOptions;
}
}