-
Notifications
You must be signed in to change notification settings - Fork 78
/
fSQLSchemaTranslation.php
5398 lines (4737 loc) · 172 KB
/
fSQLSchemaTranslation.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
/**
* Adds cross-database `CREATE TABLE`, `ALTER TABLE` and `COMMENT ON COLUMN` statements to fSQLTranslation
*
* @copyright Copyright (c) 2011-2012 Will Bond
* @author Will Bond [wb] <[email protected]>
* @license http://flourishlib.com/license
*
* @package Flourish
* @link http://flourishlib.com/fSQLSchemaTranslation
*
* @version 1.0.0b3
* @changes 1.0.0b3 Fixed associating a sequence with a column in PostgreSQL when setting auto-increment, fixed detection of some Oracle CHECK(IN) constraints, fixed default values for SQLite `ON DELETE` and `ON UPDATE` clauses [wb, 2012-01-12]
* @changes 1.0.0b2 Fixed detection of explicitly named SQLite foreign key constraints [wb, 2011-08-23]
* @changes 1.0.0b The initial implementation [wb, 2011-05-09]
*/
class fSQLSchemaTranslation
{
/**
* Converts a SQL identifier to lower case and removes double quotes
*
* @param string $identifier The SQL identifier
* @return string The unescaped identifier
*/
static private function unescapeIdentifier($identifier)
{
return str_replace('"', '', strtolower($identifier));
}
/**
* Composes text using fText if loaded
*
* @param string $message The message to compose
* @param mixed $component A string or number to insert into the message
* @param mixed ...
* @return string The composed and possible translated message
*/
static protected function compose($message)
{
$args = array_slice(func_get_args(), 1);
if (class_exists('fText', FALSE)) {
return call_user_func_array(
array('fText', 'compose'),
array($message, $args)
);
} else {
return vsprintf($message, $args);
}
}
/**
* Accepts a CREATE TABLE statement and parses out the column definitions
*
* The return value is an associative array with the keys being column
* names and the values being arrays containing the following keys:
* - definition: (string) the complete column definition
* - pieces: (array) an associative array that can be joined back together to make the definition
* - beginning
* - column_name
* - data_type
* - not_null
* - null
* - default
* - unique
* - primary_key
* - check_constraint
* - foreign_key
* - deferrable
* - comment/end
*
* @param string $sql The SQL `CREATE TABLE` statement
* @return array An associative array of information for each column - see method description for details
*/
static private function parseSQLiteColumnDefinitions($sql)
{
preg_match_all(
'#(?<=,|\(|\*/|\n)(\s*)[`"\'\[]?(\w+)[`"\'\]]?(\s+(?:[a-z]+)(?:\(\s*(\d+)(?:\s*,\s*(\d+))?\s*\))?)(?:(\s+NOT\s+NULL)|(\s+NULL)|(\s+DEFAULT\s+([^, \'\n]*|\'(?:\'\'|[^\']+)*\'))|(\s+UNIQUE)|(\s+PRIMARY\s+KEY(?:\s+AUTOINCREMENT)?)|(\s+CHECK\s*\("?\w+"?\s+IN\s+\(\s*(?:(?:[^, \'\n]+|\'(?:\'\'|[^\']+)*\')\s*,\s*)*\s*(?:[^, \'\n]+|\'(?:\'\'|[^\']+)*\')\)\)))*(\s+REFERENCES\s+[\'"`\[]?\w+[\'"`\]]?\s*\(\s*[\'"`\[]?\w+[\'"`\]]?\s*\)\s*(?:\s+(?:ON\s+DELETE|ON\s+UPDATE)\s+(?:CASCADE|NO\s+ACTION|RESTRICT|SET\s+NULL|SET\s+DEFAULT))*(\s+(?:DEFERRABLE|NOT\s+DEFERRABLE))?)?((?:\s*(?:/\*\s*((?:(?!\*/).)*?)\s*\*/))?\s*(?:,[ \t]*(?:--[ \t]*([^\n]*?)[ \t]*(?=\n)|/\*\s*((?:(?!\*/).)*?)\s*\*/)?|(?:--[ \t]*([^\n]*?)[ \t]*(?=\n))?\s*(?=\))))#msi',
$sql,
$matches,
PREG_SET_ORDER
);
$output = array();
foreach ($matches as $match) {
$comment = '';
foreach (array(16, 17, 18, 19) as $key) {
if (isset($match[$key])) {
$comment .= $match[$key];
}
}
$output[strtolower($match[2])] = array(
'definition' => $match[0],
'pieces' => array(
'beginning' => $match[1],
'column_name' => $match[2],
'data_type' => $match[3],
'not_null' => $match[6],
'null' => $match[7],
'default' => $match[8],
'unique' => $match[10],
'primary_key' => $match[11],
'check_constraint' => $match[12],
'foreign_key' => $match[13],
'deferrable' => $match[14],
'comment/end' => $match[15]
)
);
}
return $output;
}
/**
* Removes a search string from a `CREATE TABLE` statement
*
* @param string $create_table_sql The SQL `CREATE TABLE` statement
* @param string $search The string to remove
* @return string The modified `CREATE TABLE` statement
*/
static private function removeFromSQLiteCreateTable($create_table_sql, $search)
{
if (preg_match('#,(\s*--.*)?\s*$#D', $search)) {
$regex = '#' . preg_quote($search, '#') . '#';
} else {
$regex = '#,(\s*/\*.*?\*/\s*|\s*--[^\n]+\n\s*)?\s*' . preg_quote($search, '#') . '\s*#';
}
return preg_replace($regex, "\\1\n", $create_table_sql);
}
/**
* The fDatabase instance
*
* @var fDatabase
*/
private $database;
/**
* Database-specific schema information needed for translation
*
* @var array
*/
private $schema_info;
/**
* Sets up the class
*
* @param fDatabase $database The database being translated for
* @return fSQLSchemaTranslation
*/
public function __construct($database)
{
$this->database = $database;
$this->schema_info = array();
}
/**
* All requests that hit this method should be requests for callbacks
*
* @internal
*
* @param string $method The method to create a callback for
* @return callback The callback for the method requested
*/
public function __get($method)
{
return array($this, $method);
}
/**
* Adds a SQLite index to the internal schema tracker
*
* @param string $name The index name
* @param string $table The table the index applies to
* @param string $sql The SQL definition of the index
* @return void
*/
private function addSQLiteIndex($name, $table, $sql)
{
if (!isset($this->schema_info['sqlite_indexes'])) {
$this->schema_info['sqlite_indexes'] = array();
}
$this->schema_info['sqlite_indexes'][$name] = array(
'table' => $table,
'sql' => $sql
);
}
/**
* Stores the SQL used to create a table
*
* @param string $table The table to set the `CREATE TABLE` statement for
* @param string $sql The SQL used to create the table
* @return void
*/
private function addSQLiteTable($table, $sql)
{
if (!isset($this->schema_info['sqlite_create_tables'])) {
$this->getSQLiteTables();
}
$this->schema_info['sqlite_create_tables'][$table] = $sql;
}
/**
* Adds a SQLite trigger to the internal schema tracker
*
* @param string $name The trigger name
* @param string $table The table the trigger applies to
* @param string $sql The SQL definition of the trigger
* @return void
*/
private function addSQLiteTrigger($name, $table, $sql)
{
if (!isset($this->schema_info['sqlite_triggers'])) {
$this->schema_info['sqlite_triggers'] = array();
}
$this->schema_info['sqlite_triggers'][$name] = array(
'table' => $table,
'sql' => $sql
);
}
/**
* Creates a trigger for SQLite that handles an on delete clause
*
* @param array &$extra_statements An array of extra SQL statements to be added to the SQL
* @param string $referencing_table The table that contains the foreign key
* @param string $referencing_column The column the foreign key constraint is on
* @param string $referenced_table The table the foreign key references
* @param string $referenced_column The column the foreign key references
* @param string $delete_clause What is to be done on a delete
* @return string The trigger
*/
private function createSQLiteForeignKeyTriggerOnDelete(&$extra_statements, $referencing_table, $referencing_column, $referenced_table, $referenced_column, $delete_clause)
{
switch (strtolower($delete_clause)) {
case 'no action':
case 'restrict':
$name = 'fkd_res_' . $referencing_table . '_' . $referencing_column;
$extra_statements[] = 'CREATE TRIGGER ' . $name . '
BEFORE DELETE ON "' . $referenced_table . '"
FOR EACH ROW BEGIN
SELECT RAISE(ROLLBACK, \'delete on table "' . $referenced_table . '" can not be executed because it would violate the foreign key constraint on column "' . $referencing_column . '" of table "' . $referencing_table . '"\')
WHERE (SELECT "' . $referencing_column . '" FROM "' . $referencing_table . '" WHERE "' . $referencing_column . '" = OLD."' . $referenced_table . '") IS NOT NULL;
END';
$this->addSQLiteTrigger($name, $referenced_table, end($extra_statements));
break;
case 'set null':
$name = 'fkd_nul_' . $referencing_table . '_' . $referencing_column;
$extra_statements[] = 'CREATE TRIGGER ' . $name . '
BEFORE DELETE ON "' . $referenced_table . '"
FOR EACH ROW BEGIN
UPDATE "' . $referencing_table . '" SET "' . $referencing_column . '" = NULL WHERE "' . $referencing_column . '" = OLD."' . $referenced_column . '";
END';
$this->addSQLiteTrigger($name, $referenced_table, end($extra_statements));
break;
case 'cascade':
$name = 'fkd_cas_' . $referencing_table . '_' . $referencing_column;
$extra_statements[] = 'CREATE TRIGGER ' . $name . '
BEFORE DELETE ON "' . $referenced_table . '"
FOR EACH ROW BEGIN
DELETE FROM "' . $referencing_table . '" WHERE "' . $referencing_column . '" = OLD."' . $referenced_column . '";
END';
$this->addSQLiteTrigger($name, $referenced_table, end($extra_statements));
break;
}
}
/**
* Creates a trigger for SQLite that handles an on update clause
*
* @param array &$extra_statements An array of extra SQL statements to be added to the SQL
* @param string $referencing_table The table that contains the foreign key
* @param string $referencing_column The column the foreign key constraint is on
* @param string $referenced_table The table the foreign key references
* @param string $referenced_column The column the foreign key references
* @param string $update_clause What is to be done on an update
* @return string The trigger
*/
private function createSQLiteForeignKeyTriggerOnUpdate(&$extra_statements, $referencing_table, $referencing_column, $referenced_table, $referenced_column, $update_clause)
{
switch (strtolower($update_clause)) {
case 'no action':
case 'restrict':
$name = 'fku_res_' . $referencing_table . '_' . $referencing_column;
$extra_statements[] = 'CREATE TRIGGER ' . $name . '
BEFORE UPDATE ON "' . $referenced_table . '"
FOR EACH ROW BEGIN
SELECT RAISE(ROLLBACK, \'update on table "' . $referenced_table . '" can not be executed because it would violate the foreign key constraint on column "' . $referencing_column . '" of table "' . $referencing_table . '"\')
WHERE (SELECT "' . $referencing_column . '" FROM "' . $referencing_table . '" WHERE "' . $referencing_column . '" = OLD."' . $referenced_column . '") IS NOT NULL;
END';
$this->addSQLiteTrigger($name, $referenced_table, end($extra_statements));
break;
case 'set null':
$name = 'fku_nul_' . $referencing_table . '_' . $referencing_column;
$extra_statements[] = 'CREATE TRIGGER ' . $name . '
BEFORE UPDATE ON "' . $referenced_table . '"
FOR EACH ROW BEGIN
UPDATE "' . $referencing_table . '" SET "' . $referencing_column . '" = NULL WHERE OLD."' . $referenced_column . '" <> NEW."' . $referenced_column . '" AND "' . $referencing_column . '" = OLD."' . $referenced_column . '";
END';
$this->addSQLiteTrigger($name, $referenced_table, end($extra_statements));
break;
case 'cascade':
$name = 'fku_cas_' . $referencing_table . '_' . $referencing_column;
$extra_statements[] = 'CREATE TRIGGER ' . $name . '
BEFORE UPDATE ON "' . $referenced_table . '"
FOR EACH ROW BEGIN
UPDATE "' . $referencing_table . '" SET "' . $referencing_column . '" = NEW."' . $referenced_column . '" WHERE OLD."' . $referenced_column . '" <> NEW."' . $referenced_column . '" AND "' . $referencing_column . '" = OLD."' . $referenced_column . '";
END';
$this->addSQLiteTrigger($name, $referenced_table, end($extra_statements));
break;
}
}
/**
* Creates a trigger for SQLite that prevents inserting or updating to values the violate a `FOREIGN KEY` constraint
*
* @param array &$extra_statements An array of extra SQL statements to be added to the SQL
* @param string $referencing_table The table that contains the foreign key
* @param string $referencing_column The column the foriegn key constraint is on
* @param string $referenced_table The table the foreign key references
* @param string $referenced_column The column the foreign key references
* @param boolean $referencing_not_null If the referencing columns is set to not null
* @return string The trigger
*/
private function createSQLiteForeignKeyTriggerValidInsertUpdate(&$extra_statements, $referencing_table, $referencing_column, $referenced_table, $referenced_column, $referencing_not_null)
{
// Verify key on inserts
$name = 'fki_ver_' . $referencing_table . '_' . $referencing_column;
$sql = 'CREATE TRIGGER ' . $name . '
BEFORE INSERT ON "' . $referencing_table . '"
FOR EACH ROW BEGIN
SELECT RAISE(ROLLBACK, \'insert on table "' . $referencing_table . '" violates foreign key constraint on column "' . $referencing_column . '"\')
WHERE ';
if (!$referencing_not_null) {
$sql .= 'NEW."' . $referencing_column . '" IS NOT NULL AND ';
}
$sql .= ' (SELECT "' . $referenced_column . '" FROM "' . $referenced_table . '" WHERE "' . $referenced_column . '" = NEW."' . $referencing_column . '") IS NULL;
END';
$extra_statements[] = $sql;
$this->addSQLiteTrigger($name, $referencing_table, end($extra_statements));
// Verify key on updates
$name = 'fku_ver_' . $referencing_table . '_' . $referencing_column;
$sql = 'CREATE TRIGGER ' . $name . '
BEFORE UPDATE ON "' . $referencing_table . '"
FOR EACH ROW BEGIN
SELECT RAISE(ROLLBACK, \'update on table "' . $referencing_table . '" violates foreign key constraint on column "' . $referencing_column . '"\')
WHERE ';
if (!$referencing_not_null) {
$sql .= 'NEW."' . $referencing_column . '" IS NOT NULL AND ';
}
$sql .= ' (SELECT "' . $referenced_column . '" FROM "' . $referenced_table . '" WHERE "' . $referenced_column . '" = NEW."' . $referencing_column . '") IS NULL;
END';
$extra_statements[] = $sql;
$this->addSQLiteTrigger($name, $referencing_table, end($extra_statements));
}
/**
* Generates a 30 character constraint name for use with `ALTER TABLE` statements
*
* @param string $sql The `ALTER TABLE` statement
* @param string $type A 2-character string representing the type of constraint
*/
private function generateConstraintName($sql, $type)
{
$constraint = '_' . $type;
$constraint = '_' . substr(time(), -8) . $constraint;
return substr(md5(strtolower($sql)), 0, 30 - strlen($constraint)) . $constraint;
}
/**
* Returns the check constraint for a table and column
*
* @param string $schema The schema the table is in
* @param string $table The table the column is in
* @param string $column The column to get the check constraint for
* @return array|NULL An associative array with the keys: `name` and `definition` or `NULL`
*/
private function getDB2CheckConstraint($schema, $table, $column)
{
$constraint = $this->database->query(
"SELECT
CH.TEXT,
CH.CONSTNAME
FROM
SYSCAT.COLUMNS AS C INNER JOIN
SYSCAT.COLCHECKS AS CC ON
C.TABSCHEMA = CC.TABSCHEMA AND
C.TABNAME = CC.TABNAME AND
C.COLNAME = CC.COLNAME AND
CC.USAGE = 'R' INNER JOIN
SYSCAT.CHECKS AS CH ON
C.TABSCHEMA = CH.TABSCHEMA AND
C.TABNAME = CH.TABNAME AND
CH.TYPE = 'C' AND
CH.CONSTNAME = CC.CONSTNAME
WHERE
LOWER(C.TABSCHEMA) = %s AND
LOWER(C.TABNAME) = %s AND
LOWER(C.COLNAME) = %s",
$schema,
$table,
$column
);
if (!$constraint->countReturnedRows()) {
return NULL;
}
$row = $constraint->fetchRow();
return array(
'name' => $row['constname'],
'definition' => $row['text']
);
}
/**
* Returns the foreign key constraints that involve a specific table or table and column
*
* @param string $schema The schema the table is in
* @param string $table The table the column is in
* @param string $column The column to get the foreign keys for and the foreign keys that point to
* @return array An associative array of the key being the constraint name and the value being an associative array containing the keys: `schema`, `table`, `column`, `foreign_schema`, `foreign_table`, `foreign_column`, `on_delete` and `on_cascade`
*/
private function getDB2ForeignKeyConstraints($schema, $table, $column=NULL)
{
if ($column) {
$where_conditions = "((
LOWER(R.TABSCHEMA) = %s AND
LOWER(R.TABNAME) = %s AND
LOWER(K.COLNAME) = %s
) OR (
LOWER(R.REFTABSCHEMA) = %s AND
LOWER(R.REFTABNAME) = %s AND
LOWER(FK.COLNAME) = %s
))";
$params = array(
strtolower($schema),
strtolower($table),
strtolower($column),
strtolower($schema),
strtolower($table),
strtolower($column)
);
} else {
$where_conditions = "LOWER(R.REFTABSCHEMA) = %s AND LOWER(R.REFTABNAME) = %s";
$params = array(
strtolower($schema),
strtolower($table)
);
}
array_unshift(
$params,
"SELECT
R.CONSTNAME AS CONSTRAINT_NAME,
TRIM(LOWER(R.TABSCHEMA)) AS \"SCHEMA\",
LOWER(R.TABNAME) AS \"TABLE\",
LOWER(K.COLNAME) AS \"COLUMN\",
TRIM(LOWER(R.REFTABSCHEMA)) AS FOREIGN_SCHEMA,
LOWER(R.REFTABNAME) AS FOREIGN_TABLE,
LOWER(FK.COLNAME) AS FOREIGN_COLUMN,
CASE R.DELETERULE WHEN 'C' THEN 'CASCADE' WHEN 'A' THEN 'NO ACTION' WHEN 'R' THEN 'RESTRICT' ELSE 'SET NULL' END AS ON_DELETE,
CASE R.UPDATERULE WHEN 'A' THEN 'NO ACTION' WHEN 'R' THEN 'RESTRICT' END AS ON_UPDATE
FROM
SYSCAT.REFERENCES AS R INNER JOIN
SYSCAT.KEYCOLUSE AS K ON
R.CONSTNAME = K.CONSTNAME AND
R.TABSCHEMA = K.TABSCHEMA AND
R.TABNAME = K.TABNAME INNER JOIN
SYSCAT.KEYCOLUSE AS FK ON
R.REFKEYNAME = FK.CONSTNAME AND
R.REFTABSCHEMA = FK.TABSCHEMA AND
R.REFTABNAME = FK.TABNAME
WHERE
$where_conditions
ORDER BY
LOWER(R.CONSTNAME) ASC"
);
$constraints = call_user_func_array($this->database->query, $params);
$keys = array();
foreach ($constraints as $constraint) {
$name = $constraint['constraint_name'] . $constraint['table'];
$keys[$name] = $constraint;
}
return $keys;
}
/**
* Returns the primary key for a table
*
* @param string $schema The schema the table is in
* @param string $table The table to get the primary key for
* @return array The columns in the primary key
*/
private function getDB2PrimaryKeyConstraint($schema, $table)
{
$constraints = $this->database->query(
"SELECT
LOWER(C.COLNAME) AS \"COLUMN\"
FROM
SYSCAT.INDEXES AS I INNER JOIN
SYSCAT.INDEXCOLUSE AS C ON
I.INDSCHEMA = C.INDSCHEMA AND
I.INDNAME = C.INDNAME
WHERE
I.UNIQUERULE IN ('P') AND
LOWER(I.TABSCHEMA) = %s AND
LOWER(I.TABNAME) = %s
ORDER BY
LOWER(I.INDNAME) ASC
",
strtolower($schema),
strtolower($table)
);
$key = array();
foreach ($constraints as $constraint) {
$key[] = $constraint['column'];
}
return $key;
}
/**
* Returns the unique keys for a table and column
*
* @param string $schema The schema the table is in
* @param string $table The table to get the unique keys for
* @param string $column The column to filter the unique keys by
* @return array An associative array of the key being the constraint name and the value being the columns in the unique key
*/
private function getDB2UniqueConstraints($schema, $table, $column)
{
$constraints = $this->database->query(
"SELECT
CD.CONSTNAME AS CONSTRAINT_NAME,
LOWER(C.COLNAME) AS \"COLUMN\"
FROM
SYSCAT.INDEXES AS I INNER JOIN
SYSCAT.CONSTDEP AS CD ON
I.TABSCHEMA = CD.TABSCHEMA AND
I.TABNAME = CD.TABNAME AND
CD.BTYPE = 'I' AND
CD.BNAME = I.INDNAME INNER JOIN
SYSCAT.INDEXCOLUSE AS C ON
I.INDSCHEMA = C.INDSCHEMA AND
I.INDNAME = C.INDNAME
WHERE
I.UNIQUERULE IN ('U') AND
LOWER(I.TABSCHEMA) = %s AND
LOWER(I.TABNAME) = %s
ORDER BY
LOWER(I.INDNAME) ASC
",
strtolower($schema),
strtolower($table)
);
$keys = array();
foreach ($constraints as $constraint) {
if (!isset($keys[$constraint['constraint_name']])) {
$keys[$constraint['constraint_name']] = array();
}
$keys[$constraint['constraint_name']][] = $constraint['column'];
}
$new_keys = array();
$column = strtolower($column);
foreach ($keys as $name => $columns) {
if (!in_array($column, $columns)) {
continue;
}
$new_keys[$name] = $columns;
}
$keys = $new_keys;
return $keys;
}
/**
* Returns the check constraint for a column, if it exists
*
* @param string $schema The schema the column is inside of
* @param string $table The table the column is part of
* @param string $column The column name
* @return array|NULL An associative array with the keys `name` and `definition`, or `NULL`
*/
private function getMSSQLCheckConstraint($schema, $table, $column)
{
$constraint = $this->database->query(
"SELECT
cc.check_clause AS 'constraint',
ccu.constraint_name
FROM
INFORMATION_SCHEMA.COLUMNS AS c INNER JOIN
INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE AS ccu ON
c.column_name = ccu.column_name AND
c.table_name = ccu.table_name AND
c.table_catalog = ccu.table_catalog INNER JOIN
INFORMATION_SCHEMA.CHECK_CONSTRAINTS AS cc ON
ccu.constraint_name = cc.constraint_name AND
ccu.constraint_catalog = cc.constraint_catalog
WHERE
LOWER(c.table_schema) = %s AND
LOWER(c.table_name) = %s AND
LOWER(c.column_name) = %s AND
c.table_catalog = DB_NAME()",
strtolower($schema),
strtolower($table),
strtolower($column)
);
if (!$constraint->countReturnedRows()) {
return NULL;
}
$row = $constraint->fetchRow();
return array(
'name' => $row['constraint_name'],
'definition' => $row['constraint']
);
}
/**
* Returns the foreign key constraints that a column is part of
*
* @param string $schema The schema the column is inside of
* @param string $table The table the column is part of
* @param string|array $column The column name(s)
* @return array An array of constraint names that reference the column(s)
*/
private function getMSSQLForeignKeyConstraints($schema, $table, $column)
{
settype($column, 'array');
$constraints = $this->database->query(
"SELECT
LOWER(tc.table_schema + '.' + tc.table_name) AS 'table',
LOWER(tc.table_schema) AS 'schema',
LOWER(tc.table_name) AS 'table_without_schema',
LOWER(kcu.column_name) AS 'column',
kcu.constraint_name AS name
FROM
information_schema.table_constraints AS tc INNER JOIN
information_schema.key_column_usage AS kcu ON
tc.constraint_name = kcu.constraint_name AND
tc.constraint_catalog = kcu.constraint_catalog AND
tc.constraint_schema = kcu.constraint_schema AND
tc.table_name = kcu.table_name INNER JOIN
information_schema.referential_constraints AS rc ON
kcu.constraint_name = rc.constraint_name AND
kcu.constraint_catalog = rc.constraint_catalog AND
kcu.constraint_schema = rc.constraint_schema INNER JOIN
information_schema.constraint_column_usage AS ccu ON
ccu.constraint_name = rc.unique_constraint_name AND
ccu.constraint_catalog = rc.constraint_catalog AND
ccu.constraint_schema = rc.constraint_schema
WHERE
tc.constraint_type = 'FOREIGN KEY' AND
(
LOWER(tc.table_schema) = %s AND
LOWER(ccu.table_name) = %s AND
LOWER(ccu.column_name) IN (%s)
) OR (
LOWER(tc.table_schema) = %s AND
LOWER(kcu.table_name) = %s AND
LOWER(kcu.column_name) IN (%s)
) AND
tc.constraint_catalog = DB_NAME()",
strtolower($schema),
strtolower($table),
array_map('strtolower', $column),
strtolower($schema),
strtolower($table),
array_map('strtolower', $column)
);
return $constraints->fetchAllRows();
}
/**
* Returns the default constraint for a column, if it exists
*
* @param string $schema The schema the column is inside of
* @param string $table The table the column is part of
* @param string $column The column name
* @return array|NULL An associative array with the keys `name` and `definition`, or `NULL`
*/
private function getMSSQLDefaultConstraint($schema, $table, $column)
{
$constraint = $this->database->query(
"SELECT
dc.name,
CAST(dc.definition AS VARCHAR(MAX)) AS definition
FROM
information_schema.columns AS c INNER JOIN
sys.default_constraints AS dc ON
OBJECT_ID(QUOTENAME(c.table_schema) + '.' + QUOTENAME(c.table_name)) = dc.parent_object_id AND
COLUMNPROPERTY(OBJECT_ID(QUOTENAME(c.table_schema) + '.' + QUOTENAME(c.table_name)), c.column_name, 'ColumnId') = dc.parent_column_id
WHERE
LOWER(c.table_schema) = %s AND
LOWER(c.table_name) = %s AND
LOWER(c.column_name) = %s AND
c.table_catalog = DB_NAME()",
strtolower($schema),
strtolower($table),
strtolower($column)
);
if (!$constraint->countReturnedRows()) {
return NULL;
}
$row = $constraint->fetchRow();
return array(
'name' => $row['name'],
'definition' => $row['definition']
);
}
/**
* Returns the primary key constraints for a table
*
* @param string $schema The schema the table is inside of
* @param string $table The table to get the constraint for
* @return array|NULL An associative array with the keys `name`, `columns` and `autoincrement` or `NULL`
*/
private function getMSSQLPrimaryKeyConstraint($schema, $table)
{
$column_info = $this->database->query(
"SELECT
kcu.constraint_name AS constraint_name,
LOWER(kcu.column_name) AS column_name,
CASE
WHEN
COLUMNPROPERTY(OBJECT_ID(QUOTENAME(c.table_schema) + '.' + QUOTENAME(c.table_name)), c.column_name, 'IsIdentity') = 1 AND
OBJECTPROPERTY(OBJECT_ID(QUOTENAME(c.table_schema) + '.' + QUOTENAME(c.table_name)), 'IsMSShipped') = 0
THEN '1'
ELSE '0'
END AS auto_increment
FROM
information_schema.table_constraints AS con INNER JOIN
information_schema.key_column_usage AS kcu ON
con.table_name = kcu.table_name AND
con.table_schema = kcu.table_schema AND
con.constraint_name = kcu.constraint_name INNER JOIN
information_schema.columns AS c ON
c.table_name = kcu.table_name AND
c.table_schema = kcu.table_schema AND
c.column_name = kcu.column_name
WHERE
con.constraint_type = 'PRIMARY KEY' AND
LOWER(con.table_schema) = %s AND
LOWER(con.table_name) = %s AND
con.table_catalog = DB_NAME()",
strtolower($schema),
strtolower($table)
);
if (!$column_info->countReturnedRows()) {
return NULL;
}
$output = array(
'columns' => array()
);
foreach ($column_info as $row) {
$output['columns'][] = $row['column_name'];
$output['name'] = $row['constraint_name'];
$output['autoincrement'] = (boolean) $row['auto_increment'];
}
return $output;
}
/**
* Returns the unique constraints that a column is part of
*
* @param string $schema The schema the column is inside of
* @param string $table The table the column is part of
* @param string $column The column name
* @return array An associative array of constraint_name => columns
*/
private function getMSSQLUniqueConstraints($schema, $table, $column)
{
$constraint_columns = $this->database->query(
"SELECT
c.constraint_name,
LOWER(kcu.column_name) AS column_name
FROM
information_schema.table_constraints AS c INNER JOIN
information_schema.key_column_usage AS kcu ON
c.table_name = kcu.table_name AND
c.constraint_name = kcu.constraint_name
WHERE
c.constraint_name IN (
SELECT
c.constraint_name
FROM
information_schema.table_constraints AS c INNER JOIN
information_schema.key_column_usage AS kcu ON
c.table_name = kcu.table_name AND
c.constraint_name = kcu.constraint_name
WHERE
c.constraint_type = 'UNIQUE' AND
LOWER(c.table_schema) = %s AND
LOWER(c.table_name) = %s AND
LOWER(kcu.column_name) = %s AND
c.table_catalog = DB_NAME()
) AND
LOWER(c.table_schema) = %s AND
c.table_catalog = DB_NAME()
ORDER BY
c.constraint_name
",
strtolower($schema),
strtolower($table),
strtolower($column),
strtolower($schema)
);
$unique_constraints = array();
foreach ($constraint_columns as $row) {
if (!isset($unique_constraints[$row['constraint_name']])) {
$unique_constraints[$row['constraint_name']] = array();
}
$unique_constraints[$row['constraint_name']][] = $row['column_name'];
}
return $unique_constraints;
}
/**
* Returns info about all foreign keys that involve the table and one of the columns specified
*
* @param string $table The table
* @param string|array $columns The column, or an array of valid column names
* @column array An array of associative arrays containing the keys `constraint_name`, `table`, `column`, `foreign_table` and `foreign_column`
*/
private function getMySQLForeignKeys($table, $columns)
{
if (is_string($columns)) {
$columns = array($columns);
}
$columns = array_map('strtolower', $columns);
$tables = $this->getMySQLTables();
$keys = array();
foreach ($tables as $_table) {
$row = $this->database->query("SHOW CREATE TABLE %r", $_table)->fetchRow();
preg_match_all(
'#CONSTRAINT\s+"(\w+)"\s+FOREIGN KEY \("([^"]+)"\) REFERENCES "([^"]+)" \("([^"]+)"\)(?:\sON\sDELETE\s(SET\sNULL|SET\sDEFAULT|CASCADE|NO\sACTION|RESTRICT))?(?:\sON\sUPDATE\s(SET\sNULL|SET\sDEFAULT|CASCADE|NO\sACTION|RESTRICT))?#',
$row['Create Table'],
$matches,
PREG_SET_ORDER
);
foreach ($matches as $match) {
$points_to_column = strtolower($match[3]) == strtolower($table) && in_array(strtolower($match[4]), $columns);
$is_column = strtolower($_table) == strtolower($table) && in_array(strtolower($match[2]), $columns);
if (!$points_to_column && !$is_column) {
continue;
}
$temp = array(
'constraint_name' => $match[1],
'table' => $_table,
'column' => $match[2],
'foreign_table' => $match[3],
'foreign_column' => $match[4],
'on_delete' => 'NO ACTION',
'on_update' => 'NO ACTION'
);
if (!empty($match[5])) {
$temp['on_delete'] = $match[5];
}
if (!empty($match[6])) {
$temp['on_update'] = $match[6];
}
$keys[] = $temp;
}
}
return $keys;
}
/**
* Returns a list of all tables in the database
*
* @return array An array of table names
*/
private function getMySQLTables()
{
if (!isset($this->schema_info['version'])) {
$version = $this->database->query("SELECT version()")->fetchScalar();
$this->schema_info['version'] = substr($version, 0, strpos($version, '.'));
}
if ($this->schema_info['version'] <= 4) {
$sql = 'SHOW TABLES';
} else {
$sql = "SHOW FULL TABLES WHERE table_type = 'BASE TABLE'";
}
$result = $this->database->query($sql);
$tables = array();
foreach ($result as $row) {
$keys = array_keys($row);
$tables[] = $row[$keys[0]];
}
return $tables;
}
/**
* Returns an an array of the column name for a table
*
* @param string $table The table to retrieve the column names for
* @return array The column names for the table
*/
private function getSQLiteColumns($table)
{
$create_sql = $this->getSQLiteCreateTable($table);
return array_keys(self::parseSQLiteColumnDefinitions($create_sql));
}
/**
* Returns the SQL used to create a table
*
* @param string $table The table to retrieve the `CREATE TABLE` statement for
* @return string The `CREATE TABLE` SQL statement
*/
private function getSQLiteCreateTable($table)
{
if (!isset($this->schema_info['sqlite_create_tables'])) {
$this->getSQLiteTables();
}
if (!isset($this->schema_info['sqlite_create_tables'][$table])) {
return NULL;
}
return $this->schema_info['sqlite_create_tables'][$table];
}
/**
* Returns a list of all foreign keys that reference the table, and optionally, column specified
*
* @param string $table All foreign keys returned will point to this table
* @param string $column Only foreign keys pointing to this column will be returned
* @return array An array of arrays containing they keys: `table`, `column`, `foreign_table`, `foreign_column`, `on_delete` and `on_update`
*/