5
* @version $Id: db_tools.php,v 1.5 2007/11/19 13:33:13 acydburn Exp $
6
* @copyright (c) 2007 phpBB Group
7
* @license http://opensource.org/licenses/gpl-license.php GNU Public License
14
if (!defined('IN_PHPBB'))
20
* Database Tools for handling cross-db actions such as altering columns, etc.
21
* Currently not supported is returning SQL for creating tables.
24
* @note currently not used within phpBB3, but may be utilized later.
33
var $dbms_type_map = array(
36
'BINT' => 'bigint(20)',
37
'UINT' => 'mediumint(8) UNSIGNED',
38
'UINT:' => 'int(%d) UNSIGNED',
39
'TINT:' => 'tinyint(%d)',
40
'USINT' => 'smallint(4) UNSIGNED',
41
'BOOL' => 'tinyint(1) UNSIGNED',
42
'VCHAR' => 'varchar(255)',
43
'VCHAR:' => 'varchar(%d)',
44
'CHAR:' => 'char(%d)',
46
'XSTEXT_UNI'=> 'varchar(100)',
48
'STEXT_UNI' => 'varchar(255)',
51
'MTEXT' => 'mediumtext',
52
'MTEXT_UNI' => 'mediumtext',
53
'TIMESTAMP' => 'int(11) UNSIGNED',
54
'DECIMAL' => 'decimal(5,2)',
55
'DECIMAL:' => 'decimal(%d,2)',
56
'PDECIMAL' => 'decimal(6,3)',
57
'PDECIMAL:' => 'decimal(%d,3)',
58
'VCHAR_UNI' => 'varchar(255)',
59
'VCHAR_UNI:'=> 'varchar(%d)',
60
'VCHAR_CI' => 'varchar(255)',
61
'VARBINARY' => 'varbinary(255)',
66
'BINT' => 'bigint(20)',
67
'UINT' => 'mediumint(8) UNSIGNED',
68
'UINT:' => 'int(%d) UNSIGNED',
69
'TINT:' => 'tinyint(%d)',
70
'USINT' => 'smallint(4) UNSIGNED',
71
'BOOL' => 'tinyint(1) UNSIGNED',
72
'VCHAR' => 'varbinary(255)',
73
'VCHAR:' => 'varbinary(%d)',
74
'CHAR:' => 'binary(%d)',
76
'XSTEXT_UNI'=> 'blob',
78
'STEXT_UNI' => 'blob',
81
'MTEXT' => 'mediumblob',
82
'MTEXT_UNI' => 'mediumblob',
83
'TIMESTAMP' => 'int(11) UNSIGNED',
84
'DECIMAL' => 'decimal(5,2)',
85
'DECIMAL:' => 'decimal(%d,2)',
86
'PDECIMAL' => 'decimal(6,3)',
87
'PDECIMAL:' => 'decimal(%d,3)',
88
'VCHAR_UNI' => 'blob',
89
'VCHAR_UNI:'=> array('varbinary(%d)', 'limit' => array('mult', 3, 255, 'blob')),
91
'VARBINARY' => 'varbinary(255)',
96
'BINT' => 'DOUBLE PRECISION',
100
'USINT' => 'INTEGER',
102
'VCHAR' => 'VARCHAR(255) CHARACTER SET NONE',
103
'VCHAR:' => 'VARCHAR(%d) CHARACTER SET NONE',
104
'CHAR:' => 'CHAR(%d) CHARACTER SET NONE',
105
'XSTEXT' => 'BLOB SUB_TYPE TEXT CHARACTER SET NONE',
106
'STEXT' => 'BLOB SUB_TYPE TEXT CHARACTER SET NONE',
107
'TEXT' => 'BLOB SUB_TYPE TEXT CHARACTER SET NONE',
108
'MTEXT' => 'BLOB SUB_TYPE TEXT CHARACTER SET NONE',
109
'XSTEXT_UNI'=> 'VARCHAR(100) CHARACTER SET UTF8',
110
'STEXT_UNI' => 'VARCHAR(255) CHARACTER SET UTF8',
111
'TEXT_UNI' => 'BLOB SUB_TYPE TEXT CHARACTER SET UTF8',
112
'MTEXT_UNI' => 'BLOB SUB_TYPE TEXT CHARACTER SET UTF8',
113
'TIMESTAMP' => 'INTEGER',
114
'DECIMAL' => 'DOUBLE PRECISION',
115
'DECIMAL:' => 'DOUBLE PRECISION',
116
'PDECIMAL' => 'DOUBLE PRECISION',
117
'PDECIMAL:' => 'DOUBLE PRECISION',
118
'VCHAR_UNI' => 'VARCHAR(255) CHARACTER SET UTF8',
119
'VCHAR_UNI:'=> 'VARCHAR(%d) CHARACTER SET UTF8',
120
'VCHAR_CI' => 'VARCHAR(255) CHARACTER SET UTF8',
121
'VARBINARY' => 'CHAR(255) CHARACTER SET NONE',
132
'VCHAR' => '[varchar] (255)',
133
'VCHAR:' => '[varchar] (%d)',
134
'CHAR:' => '[char] (%d)',
135
'XSTEXT' => '[varchar] (1000)',
136
'STEXT' => '[varchar] (3000)',
137
'TEXT' => '[varchar] (8000)',
139
'XSTEXT_UNI'=> '[varchar] (100)',
140
'STEXT_UNI' => '[varchar] (255)',
141
'TEXT_UNI' => '[varchar] (4000)',
142
'MTEXT_UNI' => '[text]',
143
'TIMESTAMP' => '[int]',
144
'DECIMAL' => '[float]',
145
'DECIMAL:' => '[float]',
146
'PDECIMAL' => '[float]',
147
'PDECIMAL:' => '[float]',
148
'VCHAR_UNI' => '[varchar] (255)',
149
'VCHAR_UNI:'=> '[varchar] (%d)',
150
'VCHAR_CI' => '[varchar] (255)',
151
'VARBINARY' => '[varchar] (255)',
155
'INT:' => 'number(%d)',
156
'BINT' => 'number(20)',
157
'UINT' => 'number(8)',
158
'UINT:' => 'number(%d)',
159
'TINT:' => 'number(%d)',
160
'USINT' => 'number(4)',
161
'BOOL' => 'number(1)',
162
'VCHAR' => 'varchar2(255)',
163
'VCHAR:' => 'varchar2(%d)',
164
'CHAR:' => 'char(%d)',
165
'XSTEXT' => 'varchar2(1000)',
166
'STEXT' => 'varchar2(3000)',
169
'XSTEXT_UNI'=> 'varchar2(300)',
170
'STEXT_UNI' => 'varchar2(765)',
171
'TEXT_UNI' => 'clob',
172
'MTEXT_UNI' => 'clob',
173
'TIMESTAMP' => 'number(11)',
174
'DECIMAL' => 'number(5, 2)',
175
'DECIMAL:' => 'number(%d, 2)',
176
'PDECIMAL' => 'number(6, 3)',
177
'PDECIMAL:' => 'number(%d, 3)',
178
'VCHAR_UNI' => 'varchar2(765)',
179
'VCHAR_UNI:'=> array('varchar2(%d)', 'limit' => array('mult', 3, 765, 'clob')),
180
'VCHAR_CI' => 'varchar2(255)',
181
'VARBINARY' => 'raw(255)',
186
'BINT' => 'bigint(20)',
187
'UINT' => 'INTEGER UNSIGNED', //'mediumint(8) UNSIGNED',
188
'UINT:' => 'INTEGER UNSIGNED', // 'int(%d) UNSIGNED',
189
'TINT:' => 'tinyint(%d)',
190
'USINT' => 'INTEGER UNSIGNED', //'mediumint(4) UNSIGNED',
191
'BOOL' => 'INTEGER UNSIGNED', //'tinyint(1) UNSIGNED',
192
'VCHAR' => 'varchar(255)',
193
'VCHAR:' => 'varchar(%d)',
194
'CHAR:' => 'char(%d)',
195
'XSTEXT' => 'text(65535)',
196
'STEXT' => 'text(65535)',
197
'TEXT' => 'text(65535)',
198
'MTEXT' => 'mediumtext(16777215)',
199
'XSTEXT_UNI'=> 'text(65535)',
200
'STEXT_UNI' => 'text(65535)',
201
'TEXT_UNI' => 'text(65535)',
202
'MTEXT_UNI' => 'mediumtext(16777215)',
203
'TIMESTAMP' => 'INTEGER UNSIGNED', //'int(11) UNSIGNED',
204
'DECIMAL' => 'decimal(5,2)',
205
'DECIMAL:' => 'decimal(%d,2)',
206
'PDECIMAL' => 'decimal(6,3)',
207
'PDECIMAL:' => 'decimal(%d,3)',
208
'VCHAR_UNI' => 'varchar(255)',
209
'VCHAR_UNI:'=> 'varchar(%d)',
210
'VCHAR_CI' => 'varchar(255)',
211
'VARBINARY' => 'blob',
217
'UINT' => 'INT4', // unsigned
218
'UINT:' => 'INT4', // unsigned
219
'USINT' => 'INT2', // unsigned
220
'BOOL' => 'INT2', // unsigned
222
'VCHAR' => 'varchar(255)',
223
'VCHAR:' => 'varchar(%d)',
224
'CHAR:' => 'char(%d)',
225
'XSTEXT' => 'varchar(1000)',
226
'STEXT' => 'varchar(3000)',
227
'TEXT' => 'varchar(8000)',
229
'XSTEXT_UNI'=> 'varchar(100)',
230
'STEXT_UNI' => 'varchar(255)',
231
'TEXT_UNI' => 'varchar(4000)',
232
'MTEXT_UNI' => 'TEXT',
233
'TIMESTAMP' => 'INT4', // unsigned
234
'DECIMAL' => 'decimal(5,2)',
235
'DECIMAL:' => 'decimal(%d,2)',
236
'PDECIMAL' => 'decimal(6,3)',
237
'PDECIMAL:' => 'decimal(%d,3)',
238
'VCHAR_UNI' => 'varchar(255)',
239
'VCHAR_UNI:'=> 'varchar(%d)',
240
'VCHAR_CI' => 'varchar_ci',
241
'VARBINARY' => 'bytea',
245
// A list of types being unsigned for better reference in some db's
246
var $unsigned_types = array('UINT', 'UINT:', 'USINT', 'BOOL', 'TIMESTAMP');
247
var $supported_dbms = array('firebird', 'mssql', 'mysql_40', 'mysql_41', 'oracle', 'postgres', 'sqlite');
250
* Set this to true if you only want to return the 'to-be-executed' SQL statement(s) (as an array).
252
var $return_statements = false;
256
function phpbb_db_tools(&$db)
260
// Determine mapping database type
261
switch ($this->db->sql_layer)
264
$this->sql_layer = 'mysql_40';
268
if (version_compare($this->db->mysql_version, '4.1.3', '>='))
270
$this->sql_layer = 'mysql_41';
274
$this->sql_layer = 'mysql_40';
279
$this->sql_layer = 'mysql_41';
284
$this->sql_layer = 'mssql';
288
$this->sql_layer = $this->db->sql_layer;
294
* Handle passed database update array.
295
* Expected structure...
296
* Key being one of the following
297
* change_columns: Column changes (only type, not name)
298
* add_columns: Add columns to a table
299
* drop_keys: Dropping keys
300
* drop_columns: Removing/Dropping columns
301
* add_primary_keys: adding primary keys
302
* add_unique_index: adding an unique index
303
* add_index: adding an index
305
* The values are in this format:
306
* {TABLE NAME} => array(
307
* {COLUMN NAME} => array({COLUMN TYPE}, {DEFAULT VALUE}, {OPTIONAL VARIABLES}),
308
* {KEY/INDEX NAME} => array({COLUMN NAMES}),
311
* For more information have a look at /develop/create_schema_files.php (only available through CVS)
313
function perform_schema_changes($schema_changes)
315
if (empty($schema_changes))
320
$statements = array();
323
if (!empty($schema_changes['change_columns']))
325
foreach ($schema_changes['change_columns'] as $table => $columns)
327
foreach ($columns as $column_name => $column_data)
329
$result = $this->sql_column_change($table, $column_name, $column_data);
331
if ($this->return_statements)
333
$statements = array_merge($statements, $result);
340
if (!empty($schema_changes['add_columns']))
342
foreach ($schema_changes['add_columns'] as $table => $columns)
344
foreach ($columns as $column_name => $column_data)
346
// Only add the column if it does not exist yet
347
if (!$this->sql_column_exists($table, $column_name))
349
$result = $this->sql_column_add($table, $column_name, $column_data);
351
if ($this->return_statements)
353
$statements = array_merge($statements, $result);
361
if (!empty($schema_changes['drop_keys']))
363
foreach ($schema_changes['drop_keys'] as $table => $indexes)
365
foreach ($indexes as $index_name)
367
$result = $this->sql_index_drop($table, $index_name);
369
if ($this->return_statements)
371
$statements = array_merge($statements, $result);
378
if (!empty($schema_changes['drop_columns']))
380
foreach ($schema_changes['drop_columns'] as $table => $columns)
382
foreach ($columns as $column)
384
$result = $this->sql_column_remove($table, $column);
386
if ($this->return_statements)
388
$statements = array_merge($statements, $result);
395
if (!empty($schema_changes['add_primary_keys']))
397
foreach ($schema_changes['add_primary_keys'] as $table => $columns)
399
$result = $this->sql_create_primary_key($table, $columns);
401
if ($this->return_statements)
403
$statements = array_merge($statements, $result);
408
// Add unqiue indexes?
409
if (!empty($schema_changes['add_unique_index']))
411
foreach ($schema_changes['add_unique_index'] as $table => $index_array)
413
foreach ($index_array as $index_name => $column)
415
$result = $this->sql_create_unique_index($table, $index_name, $column);
417
if ($this->return_statements)
419
$statements = array_merge($statements, $result);
426
if (!empty($schema_changes['add_index']))
428
foreach ($schema_changes['add_index'] as $table => $index_array)
430
foreach ($index_array as $index_name => $column)
432
$result = $this->sql_create_index($table, $index_name, $column);
434
if ($this->return_statements)
436
$statements = array_merge($statements, $result);
442
if ($this->return_statements)
449
* Check if a specified column exist
450
* @return bool True if column exists, else false
452
function sql_column_exists($table, $column_name)
454
switch ($this->sql_layer)
459
$sql = "SHOW COLUMNS FROM $table";
460
$result = $this->db->sql_query($sql);
462
while ($row = $this->db->sql_fetchrow($result))
464
// lower case just in case
465
if (strtolower($row['Field']) == $column_name)
467
$this->db->sql_freeresult($result);
471
$this->db->sql_freeresult($result);
475
// PostgreSQL has a way of doing this in a much simpler way but would
476
// not allow us to support all versions of PostgreSQL
478
$sql = "SELECT a.attname
479
FROM pg_class c, pg_attribute a
480
WHERE c.relname = '{$table}'
482
AND a.attrelid = c.oid";
483
$result = $this->db->sql_query($sql);
484
while ($row = $this->db->sql_fetchrow($result))
486
// lower case just in case
487
if (strtolower($row['attname']) == $column_name)
489
$this->db->sql_freeresult($result);
493
$this->db->sql_freeresult($result);
498
// same deal with PostgreSQL, we must perform more complex operations than
499
// we technically could
501
$sql = "SELECT c.name
503
LEFT JOIN sysobjects o ON c.id = o.id
504
WHERE o.name = '{$table}'";
505
$result = $this->db->sql_query($sql);
506
while ($row = $this->db->sql_fetchrow($result))
508
// lower case just in case
509
if (strtolower($row['name']) == $column_name)
511
$this->db->sql_freeresult($result);
515
$this->db->sql_freeresult($result);
520
$sql = "SELECT column_name
521
FROM user_tab_columns
522
WHERE table_name = '{$table}'";
523
$result = $this->db->sql_query($sql);
524
while ($row = $this->db->sql_fetchrow($result))
526
// lower case just in case
527
if (strtolower($row['column_name']) == $column_name)
529
$this->db->sql_freeresult($result);
533
$this->db->sql_freeresult($result);
538
$sql = "SELECT RDB\$FIELD_NAME as FNAME
539
FROM RDB\$RELATION_FIELDS
540
WHERE RDB\$RELATION_NAME = '{$table}'";
541
$result = $this->db->sql_query($sql);
542
while ($row = $this->db->sql_fetchrow($result))
544
// lower case just in case
545
if (strtolower($row['fname']) == $column_name)
547
$this->db->sql_freeresult($result);
551
$this->db->sql_freeresult($result);
560
AND name = '{$table}'";
561
$result = $this->db->sql_query($sql);
568
$row = $this->db->sql_fetchrow($result);
569
$this->db->sql_freeresult($result);
571
preg_match('#\((.*)\)#s', $row['sql'], $matches);
573
$cols = trim($matches[1]);
574
$col_array = preg_split('/,(?![\s\w]+\))/m', $cols);
576
foreach ($col_array as $declaration)
578
$entities = preg_split('#\s+#', trim($declaration));
579
if ($entities[0] == 'PRIMARY')
584
if (strtolower($entities[0]) == $column_name)
595
* Private method for performing sql statements (either execute them or return them)
598
function _sql_run_sql($statements)
600
if ($this->return_statements)
605
// We could add error handling here...
606
foreach ($statements as $sql)
608
if ($sql === 'begin')
610
$this->db->sql_transaction('begin');
612
else if ($sql === 'commit')
614
$this->db->sql_transaction('commit');
618
$this->db->sql_query($sql);
626
* Function to prepare some column information for better usage
629
function sql_prepare_column_data($table_name, $column_name, $column_data)
632
if (strpos($column_data[0], ':') !== false)
634
list($orig_column_type, $column_length) = explode(':', $column_data[0]);
636
if (!is_array($this->dbms_type_map[$this->sql_layer][$orig_column_type . ':']))
638
$column_type = sprintf($this->dbms_type_map[$this->sql_layer][$orig_column_type . ':'], $column_length);
642
if (isset($this->dbms_type_map[$this->sql_layer][$orig_column_type . ':']['rule']))
644
switch ($this->dbms_type_map[$this->sql_layer][$orig_column_type . ':']['rule'][0])
647
$column_length /= $this->dbms_type_map[$this->sql_layer][$orig_column_type . ':']['rule'][1];
648
$column_length = ceil($column_length);
649
$column_type = sprintf($this->dbms_type_map[$this->sql_layer][$orig_column_type . ':'][0], $column_length);
654
if (isset($this->dbms_type_map[$this->sql_layer][$orig_column_type . ':']['limit']))
656
switch ($this->dbms_type_map[$this->sql_layer][$orig_column_type . ':']['limit'][0])
659
$column_length *= $this->dbms_type_map[$this->sql_layer][$orig_column_type . ':']['limit'][1];
660
if ($column_length > $this->dbms_type_map[$this->sql_layer][$orig_column_type . ':']['limit'][2])
662
$column_type = $this->dbms_type_map[$this->sql_layer][$orig_column_type . ':']['limit'][3];
666
$column_type = sprintf($this->dbms_type_map[$this->sql_layer][$orig_column_type . ':'][0], $column_length);
672
$orig_column_type .= ':';
676
$orig_column_type = $column_data[0];
677
$column_type = $this->dbms_type_map[$this->sql_layer][$column_data[0]];
680
// Adjust default value if db-dependant specified
681
if (is_array($column_data[1]))
683
$column_data[1] = (isset($column_data[1][$this->sql_layer])) ? $column_data[1][$this->sql_layer] : $column_data[1]['default'];
688
$return_array = array();
690
switch ($this->sql_layer)
693
$sql .= " {$column_type} ";
695
if (!is_null($column_data[1]))
697
$sql .= 'DEFAULT ' . ((is_numeric($column_data[1])) ? $column_data[1] : "'{$column_data[1]}'") . ' ';
702
// This is a UNICODE column and thus should be given it's fair share
703
if (preg_match('/^X?STEXT_UNI|VCHAR_(CI|UNI:?)/', $column_data[0]))
705
$sql .= ' COLLATE UNICODE';
711
$sql .= " {$column_type} ";
712
$sql_default = " {$column_type} ";
714
// For adding columns we need the default definition
715
if (!is_null($column_data[1]))
717
// For hexadecimal values do not use single quotes
718
if (strpos($column_data[1], '0x') === 0)
720
$sql_default .= 'DEFAULT (' . $column_data[1] . ') ';
724
$sql_default .= 'DEFAULT (' . ((is_numeric($column_data[1])) ? $column_data[1] : "'{$column_data[1]}'") . ') ';
729
$sql_default .= 'NOT NULL';
731
$return_array['column_type_sql_default'] = $sql_default;
736
$sql .= " {$column_type} ";
738
// For hexadecimal values do not use single quotes
739
if (!is_null($column_data[1]) && substr($column_type, -4) !== 'text' && substr($column_type, -4) !== 'blob')
741
$sql .= (strpos($column_data[1], '0x') === 0) ? "DEFAULT {$column_data[1]} " : "DEFAULT '{$column_data[1]}' ";
745
if (isset($column_data[2]))
747
if ($column_data[2] == 'auto_increment')
749
$sql .= ' auto_increment';
751
else if ($this->sql_layer === 'mysql_41' && $column_data[2] == 'true_sort')
753
$sql .= ' COLLATE utf8_unicode_ci';
760
$sql .= " {$column_type} ";
761
$sql .= (!is_null($column_data[1])) ? "DEFAULT '{$column_data[1]}' " : '';
763
// In Oracle empty strings ('') are treated as NULL.
764
// Therefore in oracle we allow NULL's for all DEFAULT '' entries
765
// Oracle does not like setting NOT NULL on a column that is already NOT NULL (this happens only on number fields)
766
if (preg_match('/number/i', $column_type))
768
$sql .= ($column_data[1] === '') ? '' : 'NOT NULL';
773
$return_array['column_type'] = $column_type;
775
$sql .= " {$column_type} ";
777
if (isset($column_data[2]) && $column_data[2] == 'auto_increment')
779
$default_val = "nextval('{$table_name}_seq')";
781
else if (!is_null($column_data[1]))
783
$default_val = "'" . $column_data[1] . "'";
784
$return_array['null'] = 'NOT NULL';
788
$return_array['default'] = $default_val;
790
$sql .= "DEFAULT {$default_val}";
792
// Unsigned? Then add a CHECK contraint
793
if (in_array($orig_column_type, $this->unsigned_types))
795
$return_array['constraint'] = "CHECK ({$column_name} >= 0)";
796
$sql .= " CHECK ({$column_name} >= 0)";
801
if (isset($column_data[2]) && $column_data[2] == 'auto_increment')
803
$sql .= ' INTEGER PRIMARY KEY';
807
$sql .= ' ' . $column_type;
810
$sql .= ' NOT NULL ';
811
$sql .= (!is_null($column_data[1])) ? "DEFAULT '{$column_data[1]}'" : '';
815
$return_array['column_type_sql'] = $sql;
817
return $return_array;
823
function sql_column_add($table_name, $column_name, $column_data)
825
$column_data = $this->sql_prepare_column_data($table_name, $column_name, $column_data);
826
$statements = array();
828
switch ($this->sql_layer)
831
$statements[] = 'ALTER TABLE "' . $table_name . '" ADD "' . $column_name . '" ' . $column_data['column_type_sql'];
835
$statements[] = 'ALTER TABLE [' . $table_name . '] ADD [' . $column_name . '] ' . $column_data['column_type_sql_default'];
840
$statements[] = 'ALTER TABLE `' . $table_name . '` ADD COLUMN `' . $column_name . '` ' . $column_data['column_type_sql'];
844
$statements[] = 'ALTER TABLE ' . $table_name . ' ADD ' . $column_name . ' ' . $column_data['column_type_sql'];
848
$statements[] = 'ALTER TABLE ' . $table_name . ' ADD COLUMN "' . $column_name . '" ' . $column_data['column_type_sql'];
852
if (version_compare(sqlite_libversion(), '3.0') == -1)
857
AND name = '{$table_name}'
858
ORDER BY type DESC, name;";
859
$result = $this->db->sql_query($sql);
866
$row = $this->db->sql_fetchrow($result);
867
$this->db->sql_freeresult($result);
869
$statements[] = 'begin';
871
// Create a backup table and populate it, destroy the existing one
872
$statements[] = preg_replace('#CREATE\s+TABLE\s+"?' . $table_name . '"?#i', 'CREATE TEMPORARY TABLE ' . $table_name . '_temp', $row['sql']);
873
$statements[] = 'INSERT INTO ' . $table_name . '_temp SELECT * FROM ' . $table_name;
874
$statements[] = 'DROP TABLE ' . $table_name;
876
preg_match('#\((.*)\)#s', $row['sql'], $matches);
878
$new_table_cols = trim($matches[1]);
879
$old_table_cols = preg_split('/,(?![\s\w]+\))/m', $new_table_cols);
880
$column_list = array();
882
foreach ($old_table_cols as $declaration)
884
$entities = preg_split('#\s+#', trim($declaration));
885
if ($entities[0] == 'PRIMARY')
889
$column_list[] = $entities[0];
892
$columns = implode(',', $column_list);
894
$new_table_cols = $column_name . ' ' . $column_data['column_type_sql'] . ',' . $new_table_cols;
896
// create a new table and fill it up. destroy the temp one
897
$statements[] = 'CREATE TABLE ' . $table_name . ' (' . $new_table_cols . ');';
898
$statements[] = 'INSERT INTO ' . $table_name . ' (' . $columns . ') SELECT ' . $columns . ' FROM ' . $table_name . '_temp;';
899
$statements[] = 'DROP TABLE ' . $table_name . '_temp';
901
$statements[] = 'commit';
905
$statements[] = 'ALTER TABLE ' . $table_name . ' ADD ' . $column_name . ' [' . $column_data['column_type_sql'] . ']';
910
return $this->_sql_run_sql($statements);
916
function sql_column_remove($table_name, $column_name)
918
$statements = array();
920
switch ($this->sql_layer)
923
$statements[] = 'ALTER TABLE "' . $table_name . '" DROP "' . $column_name . '"';
927
$statements[] = 'ALTER TABLE [' . $table_name . '] DROP COLUMN [' . $column_name . ']';
932
$statements[] = 'ALTER TABLE `' . $table_name . '` DROP COLUMN `' . $column_name . '`';
936
$statements[] = 'ALTER TABLE ' . $table_name . ' DROP ' . $column_name;
940
$statements[] = 'ALTER TABLE ' . $table_name . ' DROP COLUMN "' . $column_name . '"';
944
if (version_compare(sqlite_libversion(), '3.0') == -1)
949
AND name = '{$table_name}'
950
ORDER BY type DESC, name;";
951
$result = $this->db->sql_query($sql);
958
$row = $this->db->sql_fetchrow($result);
959
$this->db->sql_freeresult($result);
961
$statements[] = 'begin';
963
// Create a backup table and populate it, destroy the existing one
964
$statements[] = preg_replace('#CREATE\s+TABLE\s+"?' . $table_name . '"?#i', 'CREATE TEMPORARY TABLE ' . $table_name . '_temp', $row['sql']);
965
$statements[] = 'INSERT INTO ' . $table_name . '_temp SELECT * FROM ' . $table_name;
966
$statements[] = 'DROP TABLE ' . $table_name;
968
preg_match('#\((.*)\)#s', $row['sql'], $matches);
970
$new_table_cols = trim($matches[1]);
971
$old_table_cols = preg_split('/,(?![\s\w]+\))/m', $new_table_cols);
972
$column_list = array();
974
foreach ($old_table_cols as $declaration)
976
$entities = preg_split('#\s+#', trim($declaration));
977
if ($entities[0] == 'PRIMARY' || $entities[0] === $column_name)
981
$column_list[] = $entities[0];
984
$columns = implode(',', $column_list);
986
$new_table_cols = $new_table_cols = preg_replace('/' . $column_name . '[^,]+(?:,|$)/m', '', $new_table_cols);
988
// create a new table and fill it up. destroy the temp one
989
$statements[] = 'CREATE TABLE ' . $table_name . ' (' . $new_table_cols . ');';
990
$statements[] = 'INSERT INTO ' . $table_name . ' (' . $columns . ') SELECT ' . $columns . ' FROM ' . $table_name . '_temp;';
991
$statements[] = 'DROP TABLE ' . $table_name . '_temp';
993
$statements[] = 'commit';
997
$statements[] = 'ALTER TABLE ' . $table_name . ' DROP COLUMN ' . $column_name;
1002
return $this->_sql_run_sql($statements);
1008
function sql_index_drop($table_name, $index_name)
1010
$statements = array();
1012
switch ($this->sql_layer)
1015
$statements[] = 'DROP INDEX ' . $table_name . '.' . $index_name;
1020
$statements[] = 'DROP INDEX ' . $index_name . ' ON ' . $table_name;
1027
$statements[] = 'DROP INDEX ' . $table_name . '_' . $index_name;
1031
return $this->_sql_run_sql($statements);
1037
function sql_create_primary_key($table_name, $column)
1039
$statements = array();
1041
switch ($this->sql_layer)
1045
$statements[] = 'ALTER TABLE ' . $table_name . ' ADD PRIMARY KEY (' . implode(', ', $column) . ')';
1049
$sql = "ALTER TABLE [{$table_name}] WITH NOCHECK ADD ";
1050
$sql .= "CONSTRAINT [PK_{$table_name}] PRIMARY KEY CLUSTERED (";
1051
$sql .= '[' . implode("],\n\t\t[", $column) . ']';
1052
$sql .= ') ON [PRIMARY]';
1054
$statements[] = $sql;
1059
$statements[] = 'ALTER TABLE ' . $table_name . ' ADD PRIMARY KEY (' . implode(', ', $column) . ')';
1063
$statements[] = 'ALTER TABLE ' . $table_name . 'add CONSTRAINT pk_' . $table_name . ' PRIMARY KEY (' . implode(', ', $column) . ')';
1069
WHERE type = 'table'
1070
AND name = '{$table_name}'
1071
ORDER BY type DESC, name;";
1072
$result = $this->db->sql_query($sql);
1079
$row = $this->db->sql_fetchrow($result);
1080
$this->db->sql_freeresult($result);
1082
$statements[] = 'begin';
1084
// Create a backup table and populate it, destroy the existing one
1085
$statements[] = preg_replace('#CREATE\s+TABLE\s+"?' . $table_name . '"?#i', 'CREATE TEMPORARY TABLE ' . $table_name . '_temp', $row['sql']);
1086
$statements[] = 'INSERT INTO ' . $table_name . '_temp SELECT * FROM ' . $table_name;
1087
$statements[] = 'DROP TABLE ' . $table_name;
1089
preg_match('#\((.*)\)#s', $row['sql'], $matches);
1091
$new_table_cols = trim($matches[1]);
1092
$old_table_cols = preg_split('/,(?![\s\w]+\))/m', $new_table_cols);
1093
$column_list = array();
1095
foreach ($old_table_cols as $declaration)
1097
$entities = preg_split('#\s+#', trim($declaration));
1098
if ($entities[0] == 'PRIMARY')
1102
$column_list[] = $entities[0];
1105
$columns = implode(',', $column_list);
1107
// create a new table and fill it up. destroy the temp one
1108
$statements[] = 'CREATE TABLE ' . $table_name . ' (' . $new_table_cols . ', PRIMARY KEY (' . implode(', ', $column) . '));';
1109
$statements[] = 'INSERT INTO ' . $table_name . ' (' . $columns . ') SELECT ' . $columns . ' FROM ' . $table_name . '_temp;';
1110
$statements[] = 'DROP TABLE ' . $table_name . '_temp';
1112
$statements[] = 'commit';
1116
return $this->_sql_run_sql($statements);
1122
function sql_create_unique_index($table_name, $index_name, $column)
1124
$statements = array();
1126
switch ($this->sql_layer)
1132
$statements[] = 'CREATE UNIQUE INDEX ' . $table_name . '_' . $index_name . ' ON ' . $table_name . '(' . implode(', ', $column) . ')';
1137
$statements[] = 'CREATE UNIQUE INDEX ' . $index_name . ' ON ' . $table_name . '(' . implode(', ', $column) . ')';
1141
$statements[] = 'CREATE UNIQUE INDEX ' . $index_name . ' ON ' . $table_name . '(' . implode(', ', $column) . ') ON [PRIMARY]';
1145
return $this->_sql_run_sql($statements);
1151
function sql_create_index($table_name, $index_name, $column)
1153
$statements = array();
1155
switch ($this->sql_layer)
1161
$statements[] = 'CREATE INDEX ' . $table_name . '_' . $index_name . ' ON ' . $table_name . '(' . implode(', ', $column) . ')';
1166
$statements[] = 'CREATE INDEX ' . $index_name . ' ON ' . $table_name . '(' . implode(', ', $column) . ')';
1170
$statements[] = 'CREATE INDEX ' . $index_name . ' ON ' . $table_name . '(' . implode(', ', $column) . ') ON [PRIMARY]';
1174
return $this->_sql_run_sql($statements);
1178
* List all of the indices that belong to a table,
1183
function sql_list_index($table_name)
1185
$index_array = array();
1187
if ($this->sql_layer == 'mssql')
1189
$sql = "EXEC sp_statistics '$table_name'";
1190
$result = $this->db->sql_query($sql);
1191
while ($row = $this->db->sql_fetchrow($result))
1193
if ($row['TYPE'] == 3)
1195
$index_array[] = $row['INDEX_NAME'];
1198
$this->db->sql_freeresult($result);
1202
switch ($this->sql_layer)
1205
$sql = "SELECT LOWER(RDB\$INDEX_NAME) as index_name
1207
WHERE RDB\$RELATION_NAME = " . strtoupper($table_name) . "
1208
AND RDB\$UNIQUE_FLAG IS NULL
1209
AND RDB\$FOREIGN_KEY IS NULL";
1210
$col = 'index_name';
1214
$sql = "SELECT ic.relname as index_name
1215
FROM pg_class bc, pg_class ic, pg_index i
1216
WHERE (bc.oid = i.indrelid)
1217
AND (ic.oid = i.indexrelid)
1218
AND (bc.relname = '" . $table_name . "')
1219
AND (i.indisunique != 't')
1220
AND (i.indisprimary != 't')";
1221
$col = 'index_name';
1227
FROM ' . $table_name;
1232
$sql = "SELECT index_name
1234
WHERE table_name = '" . $table_name . "'
1235
AND generated = 'N'";
1239
$sql = "PRAGMA index_info('" . $table_name . "');";
1244
$result = $this->db->sql_query($sql);
1245
while ($row = $this->db->sql_fetchrow($result))
1247
if (($this->sql_layer == 'mysql_40' || $this->sql_layer == 'mysql_41') && !$row['Non_unique'])
1252
switch ($this->sql_layer)
1258
$row[$col] = substr($row[$col], strlen($table_name) + 1);
1262
$index_array[] = $row[$col];
1264
$this->db->sql_freeresult($result);
1267
return array_map('strtolower', $index_array);
1271
* Change column type (not name!)
1273
function sql_column_change($table_name, $column_name, $column_data)
1275
$column_data = $this->sql_prepare_column_data($table_name, $column_name, $column_data);
1276
$statements = array();
1278
switch ($this->sql_layer)
1282
$statements[] = 'ALTER TABLE "' . $table_name . '" ALTER COLUMN "' . $column_name . '" TYPE ' . ' ' . $column_data['column_type_sql'];
1286
$statements[] = 'ALTER TABLE [' . $table_name . '] ALTER COLUMN [' . $column_name . '] ' . $column_data['column_type_sql'];
1291
$statements[] = 'ALTER TABLE `' . $table_name . '` CHANGE `' . $column_name . '` `' . $column_name . '` ' . $column_data['column_type_sql'];
1295
$statements[] = 'ALTER TABLE ' . $table_name . ' MODIFY ' . $column_name . ' ' . $column_data['column_type_sql'];
1299
$sql = 'ALTER TABLE ' . $table_name . ' ';
1301
$sql_array = array();
1302
$sql_array[] = 'ALTER COLUMN ' . $column_name . ' TYPE ' . $column_data['column_type'];
1304
if (isset($column_data['null']))
1306
if ($column_data['null'] == 'NOT NULL')
1308
$sql_array[] = 'ALTER COLUMN ' . $column_name . ' SET NOT NULL';
1310
else if ($column_data['null'] == 'NULL')
1312
$sql_array[] = 'ALTER COLUMN ' . $column_name . ' DROP NOT NULL';
1316
if (isset($column_data['default']))
1318
$sql_array[] = 'ALTER COLUMN ' . $column_name . ' SET DEFAULT ' . $column_data['default'];
1321
// we don't want to double up on constraints if we change different number data types
1322
if (isset($column_data['constraint']))
1324
$constraint_sql = "SELECT consrc as constraint_data
1325
FROM pg_constraint, pg_class bc
1326
WHERE conrelid = bc.oid
1327
AND bc.relname = '{$table_name}'
1330
FROM pg_constraint as c, pg_inherits as i
1331
WHERE i.inhrelid = pg_constraint.conrelid
1332
AND c.conname = pg_constraint.conname
1333
AND c.consrc = pg_constraint.consrc
1334
AND c.conrelid = i.inhparent
1337
$constraint_exists = false;
1339
$result = $this->db->sql_query($constraint_sql);
1340
while ($row = $this->db->sql_fetchrow($result))
1342
if (trim($row['constraint_data']) == trim($column_data['constraint']))
1344
$constraint_exists = true;
1348
$this->db->sql_freeresult($result);
1350
if (!$constraint_exists)
1352
$sql_array[] = 'ADD ' . $column_data['constraint'];
1356
$sql .= implode(', ', $sql_array);
1358
$statements[] = $sql;
1365
WHERE type = 'table'
1366
AND name = '{$table_name}'
1367
ORDER BY type DESC, name;";
1368
$result = $this->db->sql_query($sql);
1375
$row = $this->db->sql_fetchrow($result);
1376
$this->db->sql_freeresult($result);
1378
$statements[] = 'begin';
1380
// Create a temp table and populate it, destroy the existing one
1381
$statements[] = preg_replace('#CREATE\s+TABLE\s+"?' . $table_name . '"?#i', 'CREATE TEMPORARY TABLE ' . $table_name . '_temp', $row['sql']);
1382
$statements[] = 'INSERT INTO ' . $table_name . '_temp SELECT * FROM ' . $table_name;
1383
$statements[] = 'DROP TABLE ' . $table_name;
1385
preg_match('#\((.*)\)#s', $row['sql'], $matches);
1387
$new_table_cols = trim($matches[1]);
1388
$old_table_cols = preg_split('/,(?![\s\w]+\))/m', $new_table_cols);
1389
$column_list = array();
1391
foreach ($old_table_cols as $key => $declaration)
1393
$entities = preg_split('#\s+#', trim($declaration));
1394
$column_list[] = $entities[0];
1395
if ($entities[0] == $column_name)
1397
$old_table_cols[$key] = $column_name . ' ' . $column_data['column_type_sql'];
1401
$columns = implode(',', $column_list);
1403
// create a new table and fill it up. destroy the temp one
1404
$statements[] = 'CREATE TABLE ' . $table_name . ' (' . implode(',', $old_table_cols) . ');';
1405
$statements[] = 'INSERT INTO ' . $table_name . ' (' . $columns . ') SELECT ' . $columns . ' FROM ' . $table_name . '_temp;';
1406
$statements[] = 'DROP TABLE ' . $table_name . '_temp';
1408
$statements[] = 'commit';
1413
return $this->_sql_run_sql($statements);
b'\\ No newline at end of file'