-
-
Notifications
You must be signed in to change notification settings - Fork 1.3k
/
SQLServerPlatform.php
1533 lines (1315 loc) · 52.4 KB
/
SQLServerPlatform.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
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
<?php
declare(strict_types=1);
namespace Doctrine\DBAL\Platforms;
use Doctrine\DBAL\Exception\ColumnLengthRequired;
use Doctrine\DBAL\Exception\InvalidLockMode;
use Doctrine\DBAL\LockMode;
use Doctrine\DBAL\Platforms\Keywords\KeywordList;
use Doctrine\DBAL\Platforms\Keywords\SQLServerKeywords;
use Doctrine\DBAL\Schema\Column;
use Doctrine\DBAL\Schema\ColumnDiff;
use Doctrine\DBAL\Schema\ForeignKeyConstraint;
use Doctrine\DBAL\Schema\Identifier;
use Doctrine\DBAL\Schema\Index;
use Doctrine\DBAL\Schema\Sequence;
use Doctrine\DBAL\Schema\Table;
use Doctrine\DBAL\Schema\TableDiff;
use Doctrine\Deprecations\Deprecation;
use InvalidArgumentException;
use function array_merge;
use function array_unique;
use function array_values;
use function count;
use function crc32;
use function dechex;
use function explode;
use function implode;
use function in_array;
use function is_array;
use function is_bool;
use function is_numeric;
use function is_string;
use function preg_match;
use function preg_match_all;
use function sprintf;
use function str_replace;
use function strpos;
use function strtoupper;
use function substr_count;
use const PREG_OFFSET_CAPTURE;
/**
* Provides the behavior, features and SQL dialect of the Microsoft SQL Server database platform
* of the oldest supported version.
*/
class SQLServerPlatform extends AbstractPlatform
{
public function getCurrentDateSQL(): string
{
return $this->getConvertExpression('date', 'GETDATE()');
}
public function getCurrentTimeSQL(): string
{
return $this->getConvertExpression('time', 'GETDATE()');
}
/**
* Returns an expression that converts an expression of one data type to another.
*
* @param string $dataType The target native data type. Alias data types cannot be used.
* @param string $expression The SQL expression to convert.
*/
private function getConvertExpression(string $dataType, string $expression): string
{
return sprintf('CONVERT(%s, %s)', $dataType, $expression);
}
protected function getDateArithmeticIntervalExpression(
string $date,
string $operator,
string $interval,
string $unit
): string {
$factorClause = '';
if ($operator === '-') {
$factorClause = '-1 * ';
}
return 'DATEADD(' . $unit . ', ' . $factorClause . $interval . ', ' . $date . ')';
}
public function getDateDiffExpression(string $date1, string $date2): string
{
return 'DATEDIFF(day, ' . $date2 . ',' . $date1 . ')';
}
/**
* {@inheritDoc}
*
* Microsoft SQL Server prefers "autoincrement" identity columns
* since sequences can only be emulated with a table.
*/
public function prefersIdentityColumns(): bool
{
return true;
}
/**
* {@inheritDoc}
*
* Microsoft SQL Server supports this through AUTO_INCREMENT columns.
*/
public function supportsIdentityColumns(): bool
{
return true;
}
public function supportsReleaseSavepoints(): bool
{
return false;
}
public function supportsSchemas(): bool
{
return true;
}
public function getDefaultSchemaName(): string
{
return 'dbo';
}
public function supportsColumnCollation(): bool
{
return true;
}
public function supportsSequences(): bool
{
return true;
}
public function getAlterSequenceSQL(Sequence $sequence): string
{
return 'ALTER SEQUENCE ' . $sequence->getQuotedName($this) .
' INCREMENT BY ' . $sequence->getAllocationSize();
}
public function getCreateSequenceSQL(Sequence $sequence): string
{
return 'CREATE SEQUENCE ' . $sequence->getQuotedName($this) .
' START WITH ' . $sequence->getInitialValue() .
' INCREMENT BY ' . $sequence->getAllocationSize() .
' MINVALUE ' . $sequence->getInitialValue();
}
/**
* {@inheritdoc}
*/
public function getDropSequenceSQL($sequence): string
{
if ($sequence instanceof Sequence) {
$sequence = $sequence->getQuotedName($this);
}
return 'DROP SEQUENCE ' . $sequence;
}
public function getListSequencesSQL(string $database): string
{
return 'SELECT seq.name,
CAST(
seq.increment AS VARCHAR(MAX)
) AS increment, -- CAST avoids driver error for sql_variant type
CAST(
seq.start_value AS VARCHAR(MAX)
) AS start_value -- CAST avoids driver error for sql_variant type
FROM sys.sequences AS seq';
}
public function getSequenceNextValSQL(string $sequence): string
{
return 'SELECT NEXT VALUE FOR ' . $sequence;
}
public function hasNativeGuidType(): bool
{
return true;
}
public function getCreateDatabaseSQL(string $name): string
{
return 'CREATE DATABASE ' . $name;
}
public function getDropDatabaseSQL(string $name): string
{
return 'DROP DATABASE ' . $name;
}
public function supportsCreateDropDatabase(): bool
{
return true;
}
public function getCreateSchemaSQL(string $schemaName): string
{
return 'CREATE SCHEMA ' . $schemaName;
}
/**
* {@inheritDoc}
*/
public function getDropForeignKeySQL($foreignKey, $table): string
{
if (! $foreignKey instanceof ForeignKeyConstraint) {
$foreignKey = new Identifier($foreignKey);
}
if (! $table instanceof Table) {
$table = new Identifier($table);
}
$foreignKey = $foreignKey->getQuotedName($this);
$table = $table->getQuotedName($this);
return 'ALTER TABLE ' . $table . ' DROP CONSTRAINT ' . $foreignKey;
}
/**
* {@inheritDoc}
*/
public function getDropIndexSQL($index, $table = null): string
{
if ($index instanceof Index) {
$index = $index->getQuotedName($this);
} elseif (! is_string($index)) {
throw new InvalidArgumentException(
__METHOD__ . '() expects $index parameter to be string or ' . Index::class . '.'
);
}
if (! isset($table)) {
return 'DROP INDEX ' . $index;
}
if ($table instanceof Table) {
$table = $table->getQuotedName($this);
}
return sprintf(
<<<SQL
IF EXISTS (SELECT * FROM sysobjects WHERE name = '%s')
ALTER TABLE %s DROP CONSTRAINT %s
ELSE
DROP INDEX %s ON %s
SQL
,
$index,
$table,
$index,
$index,
$table
);
}
/**
* {@inheritDoc}
*/
protected function _getCreateTableSQL(string $name, array $columns, array $options = []): array
{
$defaultConstraintsSql = [];
$commentsSql = [];
$tableComment = $options['comment'] ?? null;
if ($tableComment !== null) {
$commentsSql[] = $this->getCommentOnTableSQL($name, $tableComment);
}
// @todo does other code breaks because of this?
// force primary keys to be not null
foreach ($columns as &$column) {
if (! empty($column['primary'])) {
$column['notnull'] = true;
}
// Build default constraints SQL statements.
if (isset($column['default'])) {
$defaultConstraintsSql[] = 'ALTER TABLE ' . $name .
' ADD' . $this->getDefaultConstraintDeclarationSQL($name, $column);
}
if (empty($column['comment']) && ! is_numeric($column['comment'])) {
continue;
}
$commentsSql[] = $this->getCreateColumnCommentSQL($name, $column['name'], $column['comment']);
}
$columnListSql = $this->getColumnDeclarationListSQL($columns);
if (isset($options['uniqueConstraints']) && ! empty($options['uniqueConstraints'])) {
foreach ($options['uniqueConstraints'] as $constraintName => $definition) {
$columnListSql .= ', ' . $this->getUniqueConstraintDeclarationSQL($constraintName, $definition);
}
}
if (isset($options['primary']) && ! empty($options['primary'])) {
$flags = '';
if (isset($options['primary_index']) && $options['primary_index']->hasFlag('nonclustered')) {
$flags = ' NONCLUSTERED';
}
$columnListSql .= ', PRIMARY KEY' . $flags
. ' (' . implode(', ', array_unique(array_values($options['primary']))) . ')';
}
$query = 'CREATE TABLE ' . $name . ' (' . $columnListSql;
$check = $this->getCheckDeclarationSQL($columns);
if (! empty($check)) {
$query .= ', ' . $check;
}
$query .= ')';
$sql = [$query];
if (isset($options['indexes']) && ! empty($options['indexes'])) {
foreach ($options['indexes'] as $index) {
$sql[] = $this->getCreateIndexSQL($index, $name);
}
}
if (isset($options['foreignKeys'])) {
foreach ((array) $options['foreignKeys'] as $definition) {
$sql[] = $this->getCreateForeignKeySQL($definition, $name);
}
}
return array_merge($sql, $commentsSql, $defaultConstraintsSql);
}
/**
* {@inheritDoc}
*/
public function getCreatePrimaryKeySQL(Index $index, $table): string
{
if ($table instanceof Table) {
$identifier = $table->getQuotedName($this);
} else {
$identifier = $table;
}
$sql = 'ALTER TABLE ' . $identifier . ' ADD PRIMARY KEY';
if ($index->hasFlag('nonclustered')) {
$sql .= ' NONCLUSTERED';
}
return $sql . ' (' . $this->getIndexFieldDeclarationListSQL($index) . ')';
}
/**
* Returns the SQL statement for creating a column comment.
*
* SQL Server does not support native column comments,
* therefore the extended properties functionality is used
* as a workaround to store them.
* The property name used to store column comments is "MS_Description"
* which provides compatibility with SQL Server Management Studio,
* as column comments are stored in the same property there when
* specifying a column's "Description" attribute.
*
* @param string $tableName The quoted table name to which the column belongs.
* @param string $columnName The quoted column name to create the comment for.
* @param string $comment The column's comment.
*/
protected function getCreateColumnCommentSQL(string $tableName, string $columnName, string $comment): string
{
if (strpos($tableName, '.') !== false) {
[$schemaSQL, $tableSQL] = explode('.', $tableName);
$schemaSQL = $this->quoteStringLiteral($schemaSQL);
$tableSQL = $this->quoteStringLiteral($tableSQL);
} else {
$schemaSQL = "'dbo'";
$tableSQL = $this->quoteStringLiteral($tableName);
}
return $this->getAddExtendedPropertySQL(
'MS_Description',
$comment,
'SCHEMA',
$schemaSQL,
'TABLE',
$tableSQL,
'COLUMN',
$columnName
);
}
/**
* Returns the SQL snippet for declaring a default constraint.
*
* @param string $table Name of the table to return the default constraint declaration for.
* @param mixed[] $column Column definition.
*
* @throws InvalidArgumentException
*/
public function getDefaultConstraintDeclarationSQL(string $table, array $column): string
{
if (! isset($column['default'])) {
throw new InvalidArgumentException('Incomplete column definition. "default" required.');
}
$columnName = new Identifier($column['name']);
return ' CONSTRAINT ' .
$this->generateDefaultConstraintName($table, $column['name']) .
$this->getDefaultValueDeclarationSQL($column) .
' FOR ' . $columnName->getQuotedName($this);
}
/**
* {@inheritDoc}
*/
public function getCreateIndexSQL(Index $index, $table): string
{
$constraint = parent::getCreateIndexSQL($index, $table);
if ($index->isUnique() && ! $index->isPrimary()) {
$constraint = $this->_appendUniqueConstraintDefinition($constraint, $index);
}
return $constraint;
}
protected function getCreateIndexSQLFlags(Index $index): string
{
$type = '';
if ($index->isUnique()) {
$type .= 'UNIQUE ';
}
if ($index->hasFlag('clustered')) {
$type .= 'CLUSTERED ';
} elseif ($index->hasFlag('nonclustered')) {
$type .= 'NONCLUSTERED ';
}
return $type;
}
/**
* Extend unique key constraint with required filters
*/
private function _appendUniqueConstraintDefinition(string $sql, Index $index): string
{
$fields = [];
foreach ($index->getQuotedColumns($this) as $field) {
$fields[] = $field . ' IS NOT NULL';
}
return $sql . ' WHERE ' . implode(' AND ', $fields);
}
/**
* {@inheritDoc}
*/
public function getAlterTableSQL(TableDiff $diff): array
{
$queryParts = [];
$sql = [];
$columnSql = [];
$commentsSql = [];
foreach ($diff->addedColumns as $column) {
if ($this->onSchemaAlterTableAddColumn($column, $diff, $columnSql)) {
continue;
}
$columnDef = $column->toArray();
$addColumnSql = 'ADD ' . $this->getColumnDeclarationSQL($column->getQuotedName($this), $columnDef);
if (isset($columnDef['default'])) {
$addColumnSql .= ' CONSTRAINT ' .
$this->generateDefaultConstraintName($diff->name, $column->getQuotedName($this)) .
$this->getDefaultValueDeclarationSQL($columnDef);
}
$queryParts[] = $addColumnSql;
$comment = $this->getColumnComment($column);
if ($comment === '') {
continue;
}
$commentsSql[] = $this->getCreateColumnCommentSQL(
$diff->name,
$column->getQuotedName($this),
$comment
);
}
foreach ($diff->removedColumns as $column) {
if ($this->onSchemaAlterTableRemoveColumn($column, $diff, $columnSql)) {
continue;
}
$queryParts[] = 'DROP COLUMN ' . $column->getQuotedName($this);
}
foreach ($diff->changedColumns as $columnDiff) {
if ($this->onSchemaAlterTableChangeColumn($columnDiff, $diff, $columnSql)) {
continue;
}
$column = $columnDiff->column;
$comment = $this->getColumnComment($column);
$hasComment = $comment !== '';
if ($columnDiff->fromColumn instanceof Column) {
$fromComment = $this->getColumnComment($columnDiff->fromColumn);
$hasFromComment = $fromComment !== '';
if ($hasFromComment && $hasComment && $fromComment !== $comment) {
$commentsSql[] = $this->getAlterColumnCommentSQL(
$diff->name,
$column->getQuotedName($this),
$comment
);
} elseif ($hasFromComment && ! $hasComment) {
$commentsSql[] = $this->getDropColumnCommentSQL($diff->name, $column->getQuotedName($this));
} elseif (! $hasFromComment && $hasComment) {
$commentsSql[] = $this->getCreateColumnCommentSQL(
$diff->name,
$column->getQuotedName($this),
$comment
);
}
}
// Do not add query part if only comment has changed.
if ($columnDiff->hasChanged('comment') && count($columnDiff->changedProperties) === 1) {
continue;
}
$requireDropDefaultConstraint = $this->alterColumnRequiresDropDefaultConstraint($columnDiff);
if ($requireDropDefaultConstraint) {
$queryParts[] = $this->getAlterTableDropDefaultConstraintClause(
$diff->name,
$columnDiff->oldColumnName
);
}
$columnDef = $column->toArray();
$queryParts[] = 'ALTER COLUMN ' .
$this->getColumnDeclarationSQL($column->getQuotedName($this), $columnDef);
if (
! isset($columnDef['default'])
|| (! $requireDropDefaultConstraint && ! $columnDiff->hasChanged('default'))
) {
continue;
}
$queryParts[] = $this->getAlterTableAddDefaultConstraintClause($diff->name, $column);
}
foreach ($diff->renamedColumns as $oldColumnName => $column) {
if ($this->onSchemaAlterTableRenameColumn($oldColumnName, $column, $diff, $columnSql)) {
continue;
}
$oldColumnName = new Identifier($oldColumnName);
$sql[] = "sp_rename '" .
$diff->getName($this)->getQuotedName($this) . '.' . $oldColumnName->getQuotedName($this) .
"', '" . $column->getQuotedName($this) . "', 'COLUMN'";
// Recreate default constraint with new column name if necessary (for future reference).
if ($column->getDefault() === null) {
continue;
}
$queryParts[] = $this->getAlterTableDropDefaultConstraintClause(
$diff->name,
$oldColumnName->getQuotedName($this)
);
$queryParts[] = $this->getAlterTableAddDefaultConstraintClause($diff->name, $column);
}
$tableSql = [];
if ($this->onSchemaAlterTable($diff, $tableSql)) {
return array_merge($tableSql, $columnSql);
}
foreach ($queryParts as $query) {
$sql[] = 'ALTER TABLE ' . $diff->getName($this)->getQuotedName($this) . ' ' . $query;
}
$sql = array_merge($sql, $commentsSql);
$newName = $diff->getNewName();
if ($newName !== null) {
$sql[] = "sp_rename '" . $diff->getName($this)->getQuotedName($this) . "', '" . $newName->getName() . "'";
/**
* Rename table's default constraints names
* to match the new table name.
* This is necessary to ensure that the default
* constraints can be referenced in future table
* alterations as the table name is encoded in
* default constraints' names.
*/
$sql[] = "DECLARE @sql NVARCHAR(MAX) = N''; " .
"SELECT @sql += N'EXEC sp_rename N''' + dc.name + ''', N''' " .
"+ REPLACE(dc.name, '" . $this->generateIdentifierName($diff->name) . "', " .
"'" . $this->generateIdentifierName($newName->getName()) . "') + ''', ''OBJECT'';' " .
'FROM sys.default_constraints dc ' .
'JOIN sys.tables tbl ON dc.parent_object_id = tbl.object_id ' .
"WHERE tbl.name = '" . $newName->getName() . "';" .
'EXEC sp_executesql @sql';
}
$sql = array_merge(
$this->getPreAlterTableIndexForeignKeySQL($diff),
$sql,
$this->getPostAlterTableIndexForeignKeySQL($diff)
);
return array_merge($sql, $tableSql, $columnSql);
}
/**
* Returns the SQL clause for adding a default constraint in an ALTER TABLE statement.
*
* @param string $tableName The name of the table to generate the clause for.
* @param Column $column The column to generate the clause for.
*/
private function getAlterTableAddDefaultConstraintClause(string $tableName, Column $column): string
{
$columnDef = $column->toArray();
$columnDef['name'] = $column->getQuotedName($this);
return 'ADD' . $this->getDefaultConstraintDeclarationSQL($tableName, $columnDef);
}
/**
* Returns the SQL clause for dropping an existing default constraint in an ALTER TABLE statement.
*
* @param string $tableName The name of the table to generate the clause for.
* @param string $columnName The name of the column to generate the clause for.
*/
private function getAlterTableDropDefaultConstraintClause(string $tableName, string $columnName): string
{
return 'DROP CONSTRAINT ' . $this->generateDefaultConstraintName($tableName, $columnName);
}
/**
* Checks whether a column alteration requires dropping its default constraint first.
*
* Different to other database vendors SQL Server implements column default values
* as constraints and therefore changes in a column's default value as well as changes
* in a column's type require dropping the default constraint first before being to
* alter the particular column to the new definition.
*
* @param ColumnDiff $columnDiff The column diff to evaluate.
*
* @return bool True if the column alteration requires dropping its default constraint first, false otherwise.
*/
private function alterColumnRequiresDropDefaultConstraint(ColumnDiff $columnDiff): bool
{
// We can only decide whether to drop an existing default constraint
// if we know the original default value.
if (! $columnDiff->fromColumn instanceof Column) {
return false;
}
// We only need to drop an existing default constraint if we know the
// column was defined with a default value before.
if ($columnDiff->fromColumn->getDefault() === null) {
return false;
}
// We need to drop an existing default constraint if the column was
// defined with a default value before and it has changed.
if ($columnDiff->hasChanged('default')) {
return true;
}
// We need to drop an existing default constraint if the column was
// defined with a default value before and the native column type has changed.
return $columnDiff->hasChanged('type') || $columnDiff->hasChanged('fixed');
}
/**
* Returns the SQL statement for altering a column comment.
*
* SQL Server does not support native column comments,
* therefore the extended properties functionality is used
* as a workaround to store them.
* The property name used to store column comments is "MS_Description"
* which provides compatibility with SQL Server Management Studio,
* as column comments are stored in the same property there when
* specifying a column's "Description" attribute.
*
* @param string $tableName The quoted table name to which the column belongs.
* @param string $columnName The quoted column name to alter the comment for.
* @param string $comment The column's comment.
*/
protected function getAlterColumnCommentSQL(string $tableName, string $columnName, string $comment): string
{
if (strpos($tableName, '.') !== false) {
[$schemaSQL, $tableSQL] = explode('.', $tableName);
$schemaSQL = $this->quoteStringLiteral($schemaSQL);
$tableSQL = $this->quoteStringLiteral($tableSQL);
} else {
$schemaSQL = "'dbo'";
$tableSQL = $this->quoteStringLiteral($tableName);
}
return $this->getUpdateExtendedPropertySQL(
'MS_Description',
$comment,
'SCHEMA',
$schemaSQL,
'TABLE',
$tableSQL,
'COLUMN',
$columnName
);
}
/**
* Returns the SQL statement for dropping a column comment.
*
* SQL Server does not support native column comments,
* therefore the extended properties functionality is used
* as a workaround to store them.
* The property name used to store column comments is "MS_Description"
* which provides compatibility with SQL Server Management Studio,
* as column comments are stored in the same property there when
* specifying a column's "Description" attribute.
*
* @param string $tableName The quoted table name to which the column belongs.
* @param string $columnName The quoted column name to drop the comment for.
*/
protected function getDropColumnCommentSQL(string $tableName, string $columnName): string
{
if (strpos($tableName, '.') !== false) {
[$schemaSQL, $tableSQL] = explode('.', $tableName);
$schemaSQL = $this->quoteStringLiteral($schemaSQL);
$tableSQL = $this->quoteStringLiteral($tableSQL);
} else {
$schemaSQL = "'dbo'";
$tableSQL = $this->quoteStringLiteral($tableName);
}
return $this->getDropExtendedPropertySQL(
'MS_Description',
'SCHEMA',
$schemaSQL,
'TABLE',
$tableSQL,
'COLUMN',
$columnName
);
}
/**
* {@inheritdoc}
*/
protected function getRenameIndexSQL(string $oldIndexName, Index $index, string $tableName): array
{
return [sprintf(
"EXEC sp_rename N'%s.%s', N'%s', N'INDEX'",
$tableName,
$oldIndexName,
$index->getQuotedName($this)
),
];
}
/**
* Returns the SQL statement for adding an extended property to a database object.
*
* @link http://msdn.microsoft.com/en-us/library/ms180047%28v=sql.90%29.aspx
*
* @param string $name The name of the property to add.
* @param string|null $value The value of the property to add.
* @param string|null $level0Type The type of the object at level 0 the property belongs to.
* @param string|null $level0Name The name of the object at level 0 the property belongs to.
* @param string|null $level1Type The type of the object at level 1 the property belongs to.
* @param string|null $level1Name The name of the object at level 1 the property belongs to.
* @param string|null $level2Type The type of the object at level 2 the property belongs to.
* @param string|null $level2Name The name of the object at level 2 the property belongs to.
*/
public function getAddExtendedPropertySQL(
string $name,
?string $value = null,
?string $level0Type = null,
?string $level0Name = null,
?string $level1Type = null,
?string $level1Name = null,
?string $level2Type = null,
?string $level2Name = null
): string {
return 'EXEC sp_addextendedproperty ' .
'N' . $this->quoteStringLiteral($name) . ', N' . $this->quoteStringLiteral((string) $value) . ', ' .
'N' . $this->quoteStringLiteral((string) $level0Type) . ', ' . $level0Name . ', ' .
'N' . $this->quoteStringLiteral((string) $level1Type) . ', ' . $level1Name . ', ' .
'N' . $this->quoteStringLiteral((string) $level2Type) . ', ' . $level2Name;
}
/**
* Returns the SQL statement for dropping an extended property from a database object.
*
* @link http://technet.microsoft.com/en-gb/library/ms178595%28v=sql.90%29.aspx
*
* @param string $name The name of the property to drop.
* @param string|null $level0Type The type of the object at level 0 the property belongs to.
* @param string|null $level0Name The name of the object at level 0 the property belongs to.
* @param string|null $level1Type The type of the object at level 1 the property belongs to.
* @param string|null $level1Name The name of the object at level 1 the property belongs to.
* @param string|null $level2Type The type of the object at level 2 the property belongs to.
* @param string|null $level2Name The name of the object at level 2 the property belongs to.
*/
public function getDropExtendedPropertySQL(
string $name,
?string $level0Type = null,
?string $level0Name = null,
?string $level1Type = null,
?string $level1Name = null,
?string $level2Type = null,
?string $level2Name = null
): string {
return 'EXEC sp_dropextendedproperty ' .
'N' . $this->quoteStringLiteral($name) . ', ' .
'N' . $this->quoteStringLiteral((string) $level0Type) . ', ' . $level0Name . ', ' .
'N' . $this->quoteStringLiteral((string) $level1Type) . ', ' . $level1Name . ', ' .
'N' . $this->quoteStringLiteral((string) $level2Type) . ', ' . $level2Name;
}
/**
* Returns the SQL statement for updating an extended property of a database object.
*
* @link http://msdn.microsoft.com/en-us/library/ms186885%28v=sql.90%29.aspx
*
* @param string $name The name of the property to update.
* @param string|null $value The value of the property to update.
* @param string|null $level0Type The type of the object at level 0 the property belongs to.
* @param string|null $level0Name The name of the object at level 0 the property belongs to.
* @param string|null $level1Type The type of the object at level 1 the property belongs to.
* @param string|null $level1Name The name of the object at level 1 the property belongs to.
* @param string|null $level2Type The type of the object at level 2 the property belongs to.
* @param string|null $level2Name The name of the object at level 2 the property belongs to.
*/
public function getUpdateExtendedPropertySQL(
string $name,
?string $value = null,
?string $level0Type = null,
?string $level0Name = null,
?string $level1Type = null,
?string $level1Name = null,
?string $level2Type = null,
?string $level2Name = null
): string {
return 'EXEC sp_updateextendedproperty ' .
'N' . $this->quoteStringLiteral($name) . ', N' . $this->quoteStringLiteral((string) $value) . ', ' .
'N' . $this->quoteStringLiteral((string) $level0Type) . ', ' . $level0Name . ', ' .
'N' . $this->quoteStringLiteral((string) $level1Type) . ', ' . $level1Name . ', ' .
'N' . $this->quoteStringLiteral((string) $level2Type) . ', ' . $level2Name;
}
public function getEmptyIdentityInsertSQL(string $quotedTableName, string $quotedIdentifierColumnName): string
{
return 'INSERT INTO ' . $quotedTableName . ' DEFAULT VALUES';
}
public function getListTablesSQL(): string
{
// "sysdiagrams" table must be ignored as it's internal SQL Server table for Database Diagrams
// Category 2 must be ignored as it is "MS SQL Server 'pseudo-system' object[s]" for replication
return 'SELECT name, SCHEMA_NAME (uid) AS schema_name FROM sysobjects'
. " WHERE type = 'U' AND name != 'sysdiagrams' AND category != 2 ORDER BY name";
}
public function getListTableColumnsSQL(string $table, ?string $database = null): string
{
return "SELECT col.name,
type.name AS type,
col.max_length AS length,
~col.is_nullable AS notnull,
def.definition AS [default],
col.scale,
col.precision,
col.is_identity AS autoincrement,
col.collation_name AS collation,
CAST(prop.value AS NVARCHAR(MAX)) AS comment -- CAST avoids driver error for sql_variant type
FROM sys.columns AS col
JOIN sys.types AS type
ON col.user_type_id = type.user_type_id
JOIN sys.objects AS obj
ON col.object_id = obj.object_id
JOIN sys.schemas AS scm
ON obj.schema_id = scm.schema_id
LEFT JOIN sys.default_constraints def
ON col.default_object_id = def.object_id
AND col.object_id = def.parent_object_id
LEFT JOIN sys.extended_properties AS prop
ON obj.object_id = prop.major_id
AND col.column_id = prop.minor_id
AND prop.name = 'MS_Description'
WHERE obj.type = 'U'
AND " . $this->getTableWhereClause($table, 'scm.name', 'obj.name');
}
public function getListTableForeignKeysSQL(string $table, ?string $database = null): string
{
return 'SELECT f.name AS ForeignKey,
SCHEMA_NAME (f.SCHEMA_ID) AS SchemaName,
OBJECT_NAME (f.parent_object_id) AS TableName,
COL_NAME (fc.parent_object_id,fc.parent_column_id) AS ColumnName,
SCHEMA_NAME (o.SCHEMA_ID) ReferenceSchemaName,
OBJECT_NAME (f.referenced_object_id) AS ReferenceTableName,
COL_NAME(fc.referenced_object_id,fc.referenced_column_id) AS ReferenceColumnName,
f.delete_referential_action_desc,
f.update_referential_action_desc
FROM sys.foreign_keys AS f
INNER JOIN sys.foreign_key_columns AS fc
INNER JOIN sys.objects AS o ON o.OBJECT_ID = fc.referenced_object_id
ON f.OBJECT_ID = fc.constraint_object_id
WHERE ' .
$this->getTableWhereClause($table, 'SCHEMA_NAME (f.schema_id)', 'OBJECT_NAME (f.parent_object_id)');
}
public function getListTableIndexesSQL(string $table, ?string $database = null): string
{
return "SELECT idx.name AS key_name,
col.name AS column_name,
~idx.is_unique AS non_unique,
idx.is_primary_key AS [primary],
CASE idx.type
WHEN '1' THEN 'clustered'
WHEN '2' THEN 'nonclustered'
ELSE NULL
END AS flags
FROM sys.tables AS tbl
JOIN sys.schemas AS scm ON tbl.schema_id = scm.schema_id
JOIN sys.indexes AS idx ON tbl.object_id = idx.object_id
JOIN sys.index_columns AS idxcol ON idx.object_id = idxcol.object_id AND idx.index_id = idxcol.index_id
JOIN sys.columns AS col ON idxcol.object_id = col.object_id AND idxcol.column_id = col.column_id
WHERE " . $this->getTableWhereClause($table, 'scm.name', 'tbl.name') . '
ORDER BY idx.index_id ASC, idxcol.key_ordinal ASC';
}
public function getCreateViewSQL(string $name, string $sql): string
{
return 'CREATE VIEW ' . $name . ' AS ' . $sql;
}
public function getListViewsSQL(string $database): string
{
return "SELECT name FROM sysobjects WHERE type = 'V' ORDER BY name";
}
/**
* Returns the where clause to filter schema and table name in a query.
*
* @param string $table The full qualified name of the table.
* @param string $schemaColumn The name of the column to compare the schema to in the where clause.
* @param string $tableColumn The name of the column to compare the table to in the where clause.
*/
private function getTableWhereClause(string $table, string $schemaColumn, string $tableColumn): string
{
if (strpos($table, '.') !== false) {
[$schema, $table] = explode('.', $table);
$schema = $this->quoteStringLiteral($schema);
$table = $this->quoteStringLiteral($table);
} else {
$schema = 'SCHEMA_NAME()';
$table = $this->quoteStringLiteral($table);
}
return sprintf('(%s = %s AND %s = %s)', $tableColumn, $table, $schemaColumn, $schema);
}
public function getDropViewSQL(string $name): string
{
return 'DROP VIEW ' . $name;
}
public function getLocateExpression(string $string, string $substring, ?string $start = null): string
{
if ($start === null) {
return sprintf('CHARINDEX(%s, %s)', $substring, $string);
}