-
Notifications
You must be signed in to change notification settings - Fork 78
/
fSchema.php
3157 lines (2752 loc) · 103 KB
/
fSchema.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
/**
* Gets schema information for the selected database
*
* @copyright Copyright (c) 2007-2012 Will Bond
* @author Will Bond [wb] <will@flourishlib.com>
* @license http://flourishlib.com/license
*
* @package Flourish
* @link http://flourishlib.com/fSchema
*
* @version 1.0.0b51
* @changes 1.0.0b51 Fixed handling of getting tables in table creation order when a table references itself, fixed default value detection for the last column in a MySQL table [wb, 2012-01-12]
* @changes 1.0.0b50 Fixed detection of explicitly named SQLite foreign key constraints [wb, 2011-08-23]
* @changes 1.0.0b49 Added support for spatial/geometric data types in MySQL and PostgreSQL [wb, 2011-05-26]
* @changes 1.0.0b48 Fixed a bug with ::getTables() not working on MySQL 4.x, fixed ::getKeys() to always return a reset array [wb, 2011-05-24]
* @changes 1.0.0b47 Backwards Compatibility Break - ::getTables(), ::getColumnInfo(), ::getDatabases(), ::getKeys() and ::getRelationships() now return database, schema, table and column names in lowercase, added the `$creation_order` parameter to ::getTables(), fixed bugs with getting column and key information from MSSQL, Oracle and SQLite [wb, 2011-05-09]
* @changes 1.0.0b46 Enhanced SQLite schema detection to cover situations where `UNIQUE` constraints are defined separately from the table and when comments are used in `CREATE TABLE` statements [wb, 2011-02-06]
* @changes 1.0.0b45 Fixed Oracle auto incrementing detection to work with `INSERT OR UPDATE` triggers, fixed detection of dynamic default date/time/timestamp values for DB2 and Oracle [wb, 2010-12-04]
* @changes 1.0.0b44 Fixed the list of valid elements for ::getColumnInfo() [wb, 2010-11-28]
* @changes 1.0.0b43 Added the `comment` element to the information returned by ::getColumnInfo() [wb, 2010-11-28]
* @changes 1.0.0b42 Fixed a bug with MySQL detecting default `ON DELETE` clauses [wb, 2010-10-19]
* @changes 1.0.0b41 Fixed handling MySQL table names that require quoting [wb, 2010-08-24]
* @changes 1.0.0b40 Fixed bugs in the documentation and error message of ::getColumnInfo() about what are valid elements [wb, 2010-07-21]
* @changes 1.0.0b39 Fixed a regression where key detection SQL was not compatible with PostgreSQL 8.1 [wb, 2010-04-13]
* @changes 1.0.0b38 Added Oracle support to ::getDatabases() [wb, 2010-04-13]
* @changes 1.0.0b37 Fixed ::getDatabases() for MSSQL [wb, 2010-04-09]
* @changes 1.0.0b36 Fixed PostgreSQL to properly report explicit `NULL` default values via ::getColumnInfo() [wb, 2010-03-30]
* @changes 1.0.0b35 Added `max_length` values for various text and blob data types across all databases [wb, 2010-03-29]
* @changes 1.0.0b34 Added `min_value` and `max_value` attributes to ::getColumnInfo() to specify the valid range for numeric columns [wb, 2010-03-16]
* @changes 1.0.0b33 Changed it so that PostgreSQL unique indexes containing functions are ignored since they can't be properly detected at this point [wb, 2010-03-14]
* @changes 1.0.0b32 Fixed ::getTables() to not include views for MySQL [wb, 2010-03-14]
* @changes 1.0.0b31 Fixed the creation of the default caching key for ::enableCaching() [wb, 2010-03-02]
* @changes 1.0.0b30 Fixed the class to work with lower privilege Oracle accounts and added detection of Oracle number columns [wb, 2010-01-25]
* @changes 1.0.0b29 Added on_delete and on_update elements to one-to-one relationship info retrieved by ::getRelationships() [wb, 2009-12-16]
* @changes 1.0.0b28 Fixed a bug with detecting some multi-column unique constraints in SQL Server databases [wb, 2009-11-13]
* @changes 1.0.0b27 Added a parameter to ::enableCaching() to provide a key token that will allow cached values to be shared between multiple databases with the same schema [wb, 2009-10-28]
* @changes 1.0.0b26 Added the placeholder element to the output of ::getColumnInfo(), added support for PostgreSQL, MSSQL and Oracle "schemas", added support for parsing quoted SQLite identifiers [wb, 2009-10-22]
* @changes 1.0.0b25 One-to-one relationships utilizing the primary key as a foreign key are now properly detected [wb, 2009-09-22]
* @changes 1.0.0b24 Fixed MSSQL support to work with ODBC database connections [wb, 2009-09-18]
* @changes 1.0.0b23 Fixed a bug where one-to-one relationships were being listed as many-to-one [wb, 2009-07-21]
* @changes 1.0.0b22 PostgreSQL UNIQUE constraints that are created as indexes and not table constraints are now properly detected [wb, 2009-07-08]
* @changes 1.0.0b21 Added support for the UUID data type in PostgreSQL [wb, 2009-06-18]
* @changes 1.0.0b20 Add caching of merged info, improved performance of ::getColumnInfo() [wb, 2009-06-15]
* @changes 1.0.0b19 Fixed a couple of bugs with ::setKeysOverride() [wb, 2009-06-04]
* @changes 1.0.0b18 Added missing support for MySQL mediumint columns [wb, 2009-05-18]
* @changes 1.0.0b17 Fixed a bug with ::clearCache() not properly reseting the tables and databases list [wb, 2009-05-13]
* @changes 1.0.0b16 Backwards Compatibility Break - ::setCacheFile() changed to ::enableCaching() and now requires an fCache object, ::flushInfo() renamed to ::clearCache(), added Oracle support [wb, 2009-05-04]
* @changes 1.0.0b15 Added support for the three different types of identifier quoting in SQLite [wb, 2009-03-28]
* @changes 1.0.0b14 Added support for MySQL column definitions containing the COLLATE keyword [wb, 2009-03-28]
* @changes 1.0.0b13 Fixed a bug with detecting PostgreSQL columns having both a CHECK constraint and a UNIQUE constraint [wb, 2009-02-27]
* @changes 1.0.0b12 Fixed detection of multi-column primary keys in MySQL [wb, 2009-02-27]
* @changes 1.0.0b11 Fixed an issue parsing MySQL tables with comments [wb, 2009-02-25]
* @changes 1.0.0b10 Added the ::getDatabases() method [wb, 2009-02-24]
* @changes 1.0.0b9 Now detects unsigned and zerofill MySQL data types that do not have a parenthetical part [wb, 2009-02-16]
* @changes 1.0.0b8 Mapped the MySQL data type `'set'` to `'varchar'`, however valid values are not implemented yet [wb, 2009-02-01]
* @changes 1.0.0b7 Fixed a bug with detecting MySQL timestamp columns [wb, 2009-01-28]
* @changes 1.0.0b6 Fixed a bug with detecting MySQL columns that accept `NULL` [wb, 2009-01-19]
* @changes 1.0.0b5 ::setColumnInfo(): fixed a bug with not grabbing the real database schema first, made general improvements [wb, 2009-01-19]
* @changes 1.0.0b4 Added support for MySQL binary data types, numeric data type options unsigned and zerofill, and per-column character set definitions [wb, 2009-01-17]
* @changes 1.0.0b3 Fixed detection of the data type of MySQL timestamp columns, added support for dynamic default date/time values [wb, 2009-01-11]
* @changes 1.0.0b2 Fixed a bug with detecting multi-column unique keys in MySQL [wb, 2009-01-03]
* @changes 1.0.0b The initial implementation [wb, 2007-09-25]
*/
class fSchema
{
/**
* The place to cache to
*
* @var fCache
*/
private $cache = NULL;
/**
* The cache prefix to use for cache entries
*
* @var string
*/
private $cache_prefix;
/**
* The cached column info
*
* @var array
*/
private $column_info = array();
/**
* The column info to override
*
* @var array
*/
private $column_info_override = array();
/**
* A reference to an instance of the fDatabase class
*
* @var fDatabase
*/
private $database = NULL;
/**
* The databases on the current database server
*
* @var array
*/
private $databases = NULL;
/**
* The cached key info
*
* @var array
*/
private $keys = array();
/**
* The key info to override
*
* @var array
*/
private $keys_override = array();
/**
* The merged column info
*
* @var array
*/
private $merged_column_info = array();
/**
* The merged key info
*
* @var array
*/
private $merged_keys = array();
/**
* The relationships in the database
*
* @var array
*/
private $relationships = array();
/**
* The tables in the database
*
* @var array
*/
private $tables = NULL;
/**
* Sets the database
*
* @param fDatabase $database The fDatabase instance
* @return fSchema
*/
public function __construct($database)
{
$this->database = $database;
}
/**
* 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);
}
/**
* Checks to see if a column is part of a single-column `UNIQUE` key
*
* @param string $table The table the column is located in
* @param string $column The column to check
* @return boolean If the column is part of a single-column unique key
*/
private function checkForSingleColumnUniqueKey($table, $column)
{
foreach ($this->merged_keys[$table]['unique'] as $key) {
if (array($column) == $key) {
return TRUE;
}
}
if (array($column) == $this->merged_keys[$table]['primary']) {
return TRUE;
}
return FALSE;
}
/**
* Clears all of the schema info out of the object and, if set, the fCache object
*
* @internal
*
* @return void
*/
public function clearCache()
{
$this->column_info = array();
$this->databases = NULL;
$this->keys = array();
$this->merged_column_info = array();
$this->merged_keys = array();
$this->relationships = array();
$this->tables = NULL;
if ($this->cache) {
$prefix = $this->makeCachePrefix();
$this->cache->delete($prefix . 'column_info');
$this->cache->delete($prefix . 'databases');
$this->cache->delete($prefix . 'keys');
$this->cache->delete($prefix . 'merged_column_info');
$this->cache->delete($prefix . 'merged_keys');
$this->cache->delete($prefix . 'relationships');
$this->cache->delete($prefix . 'tables');
}
}
/**
* Returns an ordered array of table names, in a valid table creation order
*
* @param string $filter_table The only return this table and tables that rely on it
* @return array An array of table names
*/
private function determineTableCreationOrder($filter_table=NULL)
{
$found = array();
$ignored_found = array();
$current_tables = $this->getTables();
// Prevent an infinite loop
$last_tables = array();
while ($current_tables && $current_tables != $last_tables) {
$remaining_tables = array();
foreach ($current_tables as $table) {
$foreign_keys = $this->getKeys($table, 'foreign');
if (!$foreign_keys) {
if ($filter_table !== NULL) {
if ($table == $filter_table) {
$found[] = $table;
} else {
$ignored_found[] = $table;
}
} else {
$found[] = $table;
}
} else {
$all_dependencies_met = TRUE;
$found_dependencies = 0;
foreach ($foreign_keys as $foreign_key) {
if ($table != $foreign_key['foreign_table'] && !in_array($foreign_key['foreign_table'], $found) && !in_array($foreign_key['foreign_table'], $ignored_found)) {
$all_dependencies_met = FALSE;
break;
} elseif (in_array($foreign_key['foreign_table'], $found)) {
$found_dependencies++;
}
}
if ($all_dependencies_met) {
if ($filter_table !== NULL) {
if ($found_dependencies || $table == $filter_table) {
$found[] = $table;
} else {
$ignored_found[] = $table;
}
} else {
$found[] = $table;
}
} else {
$remaining_tables[] = $table;
}
}
}
$last_tables = $current_tables;
$current_tables = $remaining_tables;
}
return $found;
}
/**
* Sets the schema to be cached to the fCache object specified
*
* @param fCache $cache The cache to cache to
* @param string $key_token Internal use only! (this will be used in the cache key to uniquely identify the cache for this fSchema object)
* @return void
*/
public function enableCaching($cache, $key_token=NULL)
{
$this->cache = $cache;
if ($key_token !== NULL) {
$this->cache_prefix = 'fSchema::' . $this->database->getType() . '::' . $key_token . '::';
}
$prefix = $this->makeCachePrefix();
$this->column_info = $this->cache->get($prefix . 'column_info', array());
$this->databases = $this->cache->get($prefix . 'databases', NULL);
$this->keys = $this->cache->get($prefix . 'keys', array());
if (!$this->column_info_override && !$this->keys_override) {
$this->merged_column_info = $this->cache->get($prefix . 'merged_column_info', array());
$this->merged_keys = $this->cache->get($prefix . 'merged_keys', array());
$this->relationships = $this->cache->get($prefix . 'relationships', array());
}
$this->tables = $this->cache->get($prefix . 'tables', NULL);
}
/**
* Gets the column info from the database for later access
*
* @param string $table The table to fetch the column info for
* @return void
*/
private function fetchColumnInfo($table)
{
if (isset($this->column_info[$table])) {
return;
}
switch ($this->database->getType()) {
case 'db2':
$column_info = $this->fetchDB2ColumnInfo($table);
break;
case 'mssql':
$column_info = $this->fetchMSSQLColumnInfo($table);
break;
case 'mysql':
$column_info = $this->fetchMySQLColumnInfo($table);
break;
case 'oracle':
$column_info = $this->fetchOracleColumnInfo($table);
break;
case 'postgresql':
$column_info = $this->fetchPostgreSQLColumnInfo($table);
break;
case 'sqlite':
$column_info = $this->fetchSQLiteColumnInfo($table);
break;
}
if (!$column_info) {
return;
}
$this->column_info[$table] = $column_info;
if ($this->cache) {
$this->cache->set($this->makeCachePrefix() . 'column_info', $this->column_info);
}
}
/**
* Gets the column info from a DB2 database
*
* @param string $table The table to fetch the column info for
* @return array The column info for the table specified - see ::getColumnInfo() for details
*/
private function fetchDB2ColumnInfo($table)
{
$column_info = array();
$schema = strtolower($this->database->getUsername());
if (strpos($table, '.') !== FALSE) {
list ($schema, $table) = explode('.', $table);
}
$data_type_mapping = array(
'smallint' => 'integer',
'integer' => 'integer',
'bigint' => 'integer',
'timestamp' => 'timestamp',
'date' => 'date',
'time' => 'time',
'varchar' => 'varchar',
'long varchar' => 'varchar',
'vargraphic' => 'varchar',
'long vargraphic' => 'varchar',
'character' => 'char',
'graphic' => 'char',
'real' => 'float',
'decimal' => 'float',
'numeric' => 'float',
'blob' => 'blob',
'clob' => 'text',
'dbclob' => 'text'
);
$max_min_values = array(
'smallint' => array('min' => new fNumber(-32768), 'max' => new fNumber(32767)),
'integer' => array('min' => new fNumber(-2147483648), 'max' => new fNumber(2147483647)),
'bigint' => array('min' => new fNumber('-9223372036854775808'), 'max' => new fNumber('9223372036854775807'))
);
// Get the column info
$sql = "SELECT
LOWER(C.COLNAME) AS \"COLUMN\",
C.TYPENAME AS TYPE,
C.NULLS AS NULLABLE,
C.DEFAULT,
C.LENGTH AS MAX_LENGTH,
C.SCALE,
CASE WHEN C.IDENTITY = 'Y' AND (C.GENERATED = 'D' OR C.GENERATED = 'A') THEN '1' ELSE '0' END AS AUTO_INCREMENT,
CH.TEXT AS \"CONSTRAINT\",
C.REMARKS AS \"COMMENT\"
FROM
SYSCAT.COLUMNS AS C LEFT JOIN
SYSCAT.COLCHECKS AS CC ON
C.TABSCHEMA = CC.TABSCHEMA AND
C.TABNAME = CC.TABNAME AND
C.COLNAME = CC.COLNAME AND
CC.USAGE = 'R' LEFT 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
ORDER BY
C.COLNO ASC";
$result = $this->database->query($sql, strtolower($schema), strtolower($table));
foreach ($result as $row) {
$info = array();
foreach ($data_type_mapping as $data_type => $mapped_data_type) {
if (stripos($row['type'], $data_type) === 0) {
if (isset($max_min_values[$data_type])) {
$info['min_value'] = $max_min_values[$data_type]['min'];
$info['max_value'] = $max_min_values[$data_type]['max'];
}
$info['type'] = $mapped_data_type;
break;
}
}
// Handle decimal places and min/max for numeric/decimals
if (in_array(strtolower($row['type']), array('decimal', 'numeric'))) {
$info['decimal_places'] = $row['scale'];
$before_digits = str_pad('', $row['max_length'] - $row['scale'], '9');
$after_digits = str_pad('', $row['scale'], '9');
$max_min = $before_digits . ($after_digits ? '.' : '') . $after_digits;
$info['min_value'] = new fNumber('-' . $max_min);
$info['max_value'] = new fNumber($max_min);
}
if (!isset($info['type'])) {
$info['type'] = $row['type'];
}
// Handle the special data for varchar columns
if (in_array($info['type'], array('char', 'varchar', 'text', 'blob'))) {
$info['max_length'] = $row['max_length'];
}
// The generally accepted practice for boolean on DB2 is a CHAR(1) with a CHECK constraint
if ($info['type'] == 'char' && $info['max_length'] == 1 && !empty($row['constraint'])) {
if (is_resource($row['constraint'])) {
$row['constraint'] = stream_get_contents($row['constraint']);
}
if (preg_match('/^\s*"?' . preg_quote($row['column'], '/') . '"?\s+in\s+\(\s*(\'0\',\s*\'1\'|\'1\',\s*\'0\')\s*\)\s*$/i', $row['constraint'])) {
$info['type'] = 'boolean';
$info['max_length'] = NULL;
}
}
// If the column has a constraint, look for valid values
if (in_array($info['type'], array('char', 'varchar')) && !empty($row['constraint'])) {
if (preg_match('/^\s*"?' . preg_quote($row['column'], '/') . '"?\s+in\s+\((.*?)\)\s*$/i', $row['constraint'], $match)) {
if (preg_match_all("/(?<!')'((''|[^']+)*)'/", $match[1], $matches, PREG_PATTERN_ORDER)) {
$info['valid_values'] = str_replace("''", "'", $matches[1]);
}
}
}
// Handle auto increment
if ($row['auto_increment']) {
$info['auto_increment'] = TRUE;
}
// Handle default values
if ($row['default'] !== NULL) {
if ($row['default'] == 'NULL') {
$info['default'] = NULL;
} elseif (in_array($info['type'], array('timestamp', 'date', 'time')) && $row['default'][0] != "'") {
$info['default'] = str_replace(' ', '_', $row['default']);
} elseif (in_array($info['type'], array('char', 'varchar', 'text', 'timestamp', 'date', 'time')) ) {
$info['default'] = substr($row['default'], 1, -1);
} elseif ($info['type'] == 'boolean') {
$info['default'] = (boolean) substr($row['default'], 1, -1);
} else {
$info['default'] = $row['default'];
}
}
// Handle not null
$info['not_null'] = ($row['nullable'] == 'N') ? TRUE : FALSE;
$info['comment'] = $row['comment'];
$column_info[$row['column']] = $info;
}
return $column_info;
}
/**
* Fetches the key info for a DB2 database
*
* @return array The keys arrays for every table in the database - see ::getKeys() for details
*/
private function fetchDB2Keys()
{
$keys = array();
$default_schema = strtolower($this->database->getUsername());
$tables = $this->getTables();
foreach ($tables as $table) {
$keys[$table] = array();
$keys[$table]['primary'] = array();
$keys[$table]['unique'] = array();
$keys[$table]['foreign'] = array();
}
$params = array();
$sql = "(SELECT
LOWER(RTRIM(R.TABSCHEMA)) AS \"SCHEMA\",
LOWER(R.TABNAME) AS \"TABLE\",
R.CONSTNAME AS CONSTRAINT_NAME,
'foreign' AS \"TYPE\",
LOWER(K.COLNAME) AS \"COLUMN\",
LOWER(RTRIM(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,
K.COLSEQ
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 ";
$conditions = array();
foreach ($tables as $table) {
if (strpos($table, '.') === FALSE) {
$table = $default_schema . '.' . $table;
}
list ($schema, $table) = explode('.', strtolower($table));
$conditions[] = "LOWER(R.TABSCHEMA) = %s AND LOWER(R.TABNAME) = %s";
$params[] = $schema;
$params[] = $table;
}
$sql .= '((' . join(') OR( ', $conditions) . '))';
$sql .= "
) UNION (
SELECT
LOWER(RTRIM(I.TABSCHEMA)) AS \"SCHEMA\",
LOWER(I.TABNAME) AS \"TABLE\",
LOWER(I.INDNAME) AS CONSTRAINT_NAME,
CASE I.UNIQUERULE WHEN 'U' THEN 'unique' ELSE 'primary' END AS \"TYPE\",
LOWER(C.COLNAME) AS \"COLUMN\",
NULL AS FOREIGN_SCHEMA,
NULL AS FOREIGN_TABLE,
NULL AS FOREIGN_COLUMN,
NULL AS ON_DELETE,
NULL AS ON_UPDATE,
C.COLSEQ
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 ('U', 'P') AND
";
$conditions = array();
foreach ($tables as $table) {
if (strpos($table, '.') === FALSE) {
$table = $default_schema . '.' . $table;
}
list ($schema, $table) = explode('.', strtolower($table));
$conditions[] = "LOWER(I.TABSCHEMA) = %s AND LOWER(I.TABNAME) = %s";
$params[] = $schema;
$params[] = $table;
}
$sql .= '((' . join(') OR( ', $conditions) . '))';
$sql .= "
)
ORDER BY 4, 1, 2, 3, 11";
$result = $this->database->query($sql, $params);
$last_name = '';
$last_table = '';
$last_type = '';
foreach ($result as $row) {
if ($row['constraint_name'] != $last_name) {
if ($last_name) {
if ($last_type == 'foreign' || $last_type == 'unique') {
$keys[$last_table][$last_type][] = $temp;
} else {
$keys[$last_table][$last_type] = $temp;
}
}
$temp = array();
if ($row['type'] == 'foreign') {
$temp['column'] = $row['column'];
$temp['foreign_table'] = $row['foreign_table'];
if ($row['foreign_schema'] != $default_schema) {
$temp['foreign_table'] = $row['foreign_schema'] . '.' . $temp['foreign_table'];
}
$temp['foreign_column'] = $row['foreign_column'];
$temp['on_delete'] = 'no_action';
$temp['on_update'] = 'no_action';
if (!empty($row['on_delete'])) {
$temp['on_delete'] = $row['on_delete'];
}
if (!empty($row['on_update'])) {
$temp['on_update'] = $row['on_update'];
}
} else {
$temp[] = $row['column'];
}
$last_table = $row['table'];
if ($row['schema'] != $default_schema) {
$last_table = $row['schema'] . '.' . $last_table;
}
$last_name = $row['constraint_name'];
$last_type = $row['type'];
} else {
$temp[] = $row['column'];
}
}
if (isset($temp)) {
if ($last_type == 'foreign' || $last_type == 'unique') {
$keys[$last_table][$last_type][] = $temp;
} else {
$keys[$last_table][$last_type] = $temp;
}
}
return $keys;
}
/**
* Gets the `PRIMARY KEY`, `FOREIGN KEY` and `UNIQUE` key constraints from the database
*
* @return void
*/
private function fetchKeys()
{
if ($this->keys) {
return;
}
switch ($this->database->getType()) {
case 'db2':
$keys = $this->fetchDB2Keys();
break;
case 'mssql':
$keys = $this->fetchMSSQLKeys();
break;
case 'mysql':
$keys = $this->fetchMySQLKeys();
break;
case 'oracle':
$keys = $this->fetchOracleKeys();
break;
case 'postgresql':
$keys = $this->fetchPostgreSQLKeys();
break;
case 'sqlite':
$keys = $this->fetchSQLiteKeys();
break;
}
$this->keys = $keys;
if ($this->cache) {
$this->cache->set($this->makeCachePrefix() . 'keys', $this->keys);
}
}
/**
* Gets the column info from a MSSQL database
*
* @param string $table The table to fetch the column info for
* @return array The column info for the table specified - see ::getColumnInfo() for details
*/
private function fetchMSSQLColumnInfo($table)
{
$column_info = array();
$schema = 'dbo';
if (strpos($table, '.') !== FALSE) {
list ($schema, $table) = explode('.', $table);
}
$data_type_mapping = array(
'bit' => 'boolean',
'tinyint' => 'integer',
'smallint' => 'integer',
'int' => 'integer',
'bigint' => 'integer',
'timestamp' => 'integer',
'datetime' => 'timestamp',
'smalldatetime' => 'timestamp',
'datetime2' => 'timestamp',
'date' => 'date',
'time' => 'time',
'varchar' => 'varchar',
'nvarchar' => 'varchar',
'uniqueidentifier' => 'varchar',
'char' => 'char',
'nchar' => 'char',
'real' => 'float',
'float' => 'float',
'money' => 'float',
'smallmoney' => 'float',
'decimal' => 'float',
'numeric' => 'float',
'binary' => 'blob',
'varbinary' => 'blob',
'image' => 'blob',
'text' => 'text',
'ntext' => 'text',
'xml' => 'text'
);
$max_min_values = array(
'tinyint' => array('min' => new fNumber(0), 'max' => new fNumber(255)),
'smallint' => array('min' => new fNumber(-32768), 'max' => new fNumber(32767)),
'int' => array('min' => new fNumber(-2147483648), 'max' => new fNumber(2147483647)),
'bigint' => array('min' => new fNumber('-9223372036854775808'), 'max' => new fNumber('9223372036854775807')),
'smallmoney' => array('min' => new fNumber('-214748.3648'), 'max' => new fNumber('214748.3647')),
'money' => array('min' => new fNumber('-922337203685477.5808'), 'max' => new fNumber('922337203685477.5807'))
);
// Get the column info
$sql = "SELECT
LOWER(c.column_name) AS 'column',
c.data_type AS 'type',
c.is_nullable AS nullable,
c.column_default AS 'default',
c.character_maximum_length AS max_length,
c.numeric_precision AS precision,
c.numeric_scale AS decimal_places,
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,
cc.check_clause AS 'constraint',
CAST(ex.value AS VARCHAR(7500)) AS 'comment'
FROM
INFORMATION_SCHEMA.COLUMNS AS c LEFT 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 LEFT JOIN
INFORMATION_SCHEMA.CHECK_CONSTRAINTS AS cc ON
ccu.constraint_name = cc.constraint_name AND
ccu.constraint_catalog = cc.constraint_catalog";
if (version_compare($this->database->getVersion(), 9, '<')) {
$sql .= " LEFT JOIN sysproperties AS ex ON ex.id = OBJECT_ID(QUOTENAME(c.table_schema) + '.' + QUOTENAME(c.table_name)) AND ex.smallid = COLUMNPROPERTY(OBJECT_ID(QUOTENAME(c.table_schema) + '.' + QUOTENAME(c.table_name)), c.column_name, 'ColumnId') AND ex.name = 'MS_Description' AND OBJECTPROPERTY(OBJECT_ID(QUOTENAME(c.table_schema) + '.' + QUOTENAME(c.table_name)), 'IsMsShipped') = 0 ";
} else {
$sql .= " LEFT JOIN SYS.EXTENDED_PROPERTIES AS ex ON ex.major_id = OBJECT_ID(QUOTENAME(c.table_schema) + '.' + QUOTENAME(c.table_name)) AND ex.minor_id = COLUMNPROPERTY(OBJECT_ID(QUOTENAME(c.table_schema) + '.' + QUOTENAME(c.table_name)), c.column_name, 'ColumnId') AND ex.name = 'MS_Description' AND OBJECTPROPERTY(OBJECT_ID(QUOTENAME(c.table_schema) + '.' + QUOTENAME(c.table_name)), 'IsMsShipped') = 0 ";
}
$sql .= "
WHERE
LOWER(c.table_name) = %s AND
LOWER(c.table_schema) = %s AND
c.table_catalog = DB_NAME()";
$result = $this->database->query($sql, strtolower($table), strtolower($schema));
foreach ($result as $row) {
$info = array();
foreach ($data_type_mapping as $data_type => $mapped_data_type) {
if (stripos($row['type'], $data_type) === 0) {
if (isset($max_min_values[$data_type])) {
$info['min_value'] = $max_min_values[$data_type]['min'];
$info['max_value'] = $max_min_values[$data_type]['max'];
}
$info['type'] = $mapped_data_type;
break;
}
}
// Handle decimal places and min/max for numeric/decimals
if (in_array(strtolower($row['type']), array('decimal', 'numeric'))) {
$info['decimal_places'] = $row['decimal_places'];
$before_digits = str_pad('', $row['precision'] - $row['decimal_places'], '9');
$after_digits = str_pad('', $row['decimal_places'], '9');
$max_min = $before_digits . ($after_digits ? '.' : '') . $after_digits;
$info['min_value'] = new fNumber('-' . $max_min);
$info['max_value'] = new fNumber($max_min);
}
if (!isset($info['type'])) {
$info['type'] = $row['type'];
}
// Handle decimal places for money/smallmoney
if (in_array($row['type'], array('money', 'smallmoney'))) {
$info['decimal_places'] = 2;
}
// Handle the special data for varchar columns
if (in_array($info['type'], array('char', 'varchar', 'text', 'blob'))) {
if ($row['type'] == 'uniqueidentifier') {
$row['max_length'] = 32;
} elseif ($row['max_length'] == -1) {
$row['max_length'] = $row['type'] == 'nvarchar' ? 1073741823 : 2147483647;
}
$info['max_length'] = $row['max_length'];
}
// If the column has a constraint, look for valid values
if (in_array($info['type'], array('char', 'varchar')) && !empty($row['constraint'])) {
if (preg_match('#^\(((?:(?: OR )?\[[^\]]+\]\s*=\s*\'(?:\'\'|[^\']+)*\')+)\)$#D', $row['constraint'], $matches)) {
$valid_values = explode(' OR ', $matches[1]);
foreach ($valid_values as $key => $value) {
$value = preg_replace('#^\s*\[' . preg_quote($row['column'], '#') . '\]\s*=\s*\'(.*)\'\s*$#', '\1', $value);
$valid_values[$key] = str_replace("''", "'", $value);
}
// SQL Server turns CHECK constraint values into a reversed list, so we fix it here
$info['valid_values'] = array_reverse($valid_values);
}
}
// Handle auto increment
if ($row['auto_increment']) {
$info['auto_increment'] = TRUE;
}
// Handle default values
if ($row['default'] !== NULL) {
if ($row['default'] == '(getdate())') {
$info['default'] = 'CURRENT_TIMESTAMP';
} elseif (in_array($info['type'], array('char', 'varchar', 'text', 'timestamp')) ) {
$info['default'] = substr($row['default'], 2, -2);
} elseif ($info['type'] == 'boolean') {
$info['default'] = (boolean) substr($row['default'], 2, -2);
} elseif (in_array($info['type'], array('integer', 'float')) ) {
$info['default'] = str_replace(array('(', ')'), '', $row['default']);
} else {
$info['default'] = pack('H*', substr($row['default'], 3, -1));
}
}
// Handle not null
$info['not_null'] = ($row['nullable'] == 'NO') ? TRUE : FALSE;
$info['comment'] = $row['comment'];
$column_info[$row['column']] = $info;
}
return $column_info;
}
/**
* Fetches the key info for an MSSQL database
*
* @return array The key info arrays for every table in the database - see ::getKeys() for details
*/
private function fetchMSSQLKeys()
{
$keys = array();
$tables = $this->getTables();
foreach ($tables as $table) {
$keys[$table] = array();
$keys[$table]['primary'] = array();
$keys[$table]['unique'] = array();
$keys[$table]['foreign'] = array();
}
$sql = "SELECT
LOWER(c.table_schema) AS \"schema\",
LOWER(c.table_name) AS \"table\",
kcu.constraint_name AS constraint_name,
CASE c.constraint_type
WHEN 'PRIMARY KEY' THEN 'primary'
WHEN 'FOREIGN KEY' THEN 'foreign'
WHEN 'UNIQUE' THEN 'unique'
END AS 'type',
LOWER(kcu.column_name) AS 'column',
LOWER(ccu.table_schema) AS foreign_schema,
LOWER(ccu.table_name) AS foreign_table,
LOWER(ccu.column_name) AS foreign_column,
REPLACE(LOWER(rc.delete_rule), ' ', '_') AS on_delete,
REPLACE(LOWER(rc.update_rule), ' ', '_') AS on_update
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 LEFT JOIN
INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS AS rc ON
c.constraint_name = rc.constraint_name LEFT JOIN
INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE AS ccu ON
ccu.constraint_name = rc.unique_constraint_name
WHERE
c.constraint_catalog = DB_NAME() AND
c.table_name != 'sysdiagrams'
ORDER BY
LOWER(c.table_schema),
LOWER(c.table_name),
c.constraint_type,
LOWER(kcu.constraint_name),
kcu.ordinal_position,
LOWER(kcu.column_name)";
$result = $this->database->query($sql);
$last_name = '';
$last_table = '';
$last_type = '';
foreach ($result as $row) {
if ($row['constraint_name'] != $last_name) {
if ($last_name) {
if ($last_type == 'foreign' || $last_type == 'unique') {
if (!isset($keys[$last_table][$last_type])) {
$keys[$last_table][$last_type] = array();
}
$keys[$last_table][$last_type][] = $temp;
} else {
$keys[$last_table][$last_type] = $temp;
}
}
$temp = array();
if ($row['type'] == 'foreign') {
$temp['column'] = $row['column'];
$temp['foreign_table'] = $row['foreign_table'];
if ($row['foreign_schema'] != 'dbo') {
$temp['foreign_table'] = $row['foreign_schema'] . '.' . $temp['foreign_table'];
}
$temp['foreign_column'] = $row['foreign_column'];
$temp['on_delete'] = 'no_action';
$temp['on_update'] = 'no_action';