3 * StatusNet, the distributed open-source microblogging tool
5 * Database schema utilities
9 * LICENCE: This program is free software: you can redistribute it and/or modify
10 * it under the terms of the GNU Affero General Public License as published by
11 * the Free Software Foundation, either version 3 of the License, or
12 * (at your option) any later version.
14 * This program is distributed in the hope that it will be useful,
15 * but WITHOUT ANY WARRANTY; without even the implied warranty of
16 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
17 * GNU Affero General Public License for more details.
19 * You should have received a copy of the GNU Affero General Public License
20 * along with this program. If not, see <http://www.gnu.org/licenses/>.
24 * @author Evan Prodromou <evan@status.net>
25 * @copyright 2009 StatusNet, Inc.
26 * @license http://www.fsf.org/licensing/licenses/agpl-3.0.html GNU Affero General Public License version 3.0
27 * @link http://status.net/
30 if (!defined('STATUSNET')) {
35 * Class representing the database schema
37 * A class representing the database schema. Can be used to
38 * manipulate the schema -- especially for plugins and upgrade
43 * @author Evan Prodromou <evan@status.net>
44 * @license http://www.fsf.org/licensing/licenses/agpl-3.0.html GNU Affero General Public License version 3.0
45 * @link http://status.net/
48 class MysqlSchema extends Schema
50 static $_single = null;
51 protected $conn = null;
55 * Main public entry point. Use this to get
56 * the singleton object.
58 * @return Schema the (single) Schema object
63 if (empty(self::$_single)) {
64 self::$_single = new Schema();
66 return self::$_single;
70 * Returns a TableDef object for the table
71 * in the schema with the given name.
73 * Throws an exception if the table is not found.
75 * @param string $table Name of the table to get
77 * @return TableDef tabledef for that table.
78 * @throws SchemaTableMissingException
81 public function getTableDef($table)
86 // Pull column data from INFORMATION_SCHEMA
87 $columns = $this->fetchMetaInfo($table, 'COLUMNS', 'ORDINAL_POSITION');
88 if (count($columns) == 0) {
89 throw new SchemaTableMissingException("No such table: $table");
92 foreach ($columns as $row) {
94 $name = $row['COLUMN_NAME'];
97 // warning -- 'unsigned' attr on numbers isn't given in DATA_TYPE and friends.
98 // It is stuck in on COLUMN_TYPE though (eg 'bigint(20) unsigned')
99 $field['type'] = $type = $row['DATA_TYPE'];
101 if ($type == 'char' || $type == 'varchar') {
102 if ($row['CHARACTER_MAXIMUM_LENGTH'] !== null) {
103 $field['length'] = intval($row['CHARACTER_MAXIMUM_LENGTH']);
106 if ($type == 'decimal') {
107 // Other int types may report these values, but they're irrelevant.
109 if ($row['NUMERIC_PRECISION'] !== null) {
110 $field['precision'] = intval($row['NUMERIC_PRECISION']);
112 if ($row['NUMERIC_SCALE'] !== null) {
113 $field['scale'] = intval($row['NUMERIC_SCALE']);
116 if ($row['IS_NULLABLE'] == 'NO') {
117 $field['not null'] = true;
119 if ($row['COLUMN_DEFAULT'] !== null) {
120 // Hack for timestamp cols
121 if ($type == 'timestamp' && $row['COLUMN_DEFAULT'] == 'CURRENT_TIMESTAMP') {
124 $field['default'] = $row['COLUMN_DEFAULT'];
125 if ($this->isNumericType($type)) {
126 $field['default'] = intval($field['default']);
130 if ($row['COLUMN_KEY'] !== null) {
131 // We'll need to look up key info...
134 if ($row['COLUMN_COMMENT'] !== null && $row['COLUMN_COMMENT'] != '') {
135 $field['description'] = $row['COLUMN_COMMENT'];
138 $extra = $row['EXTRA'];
140 if (preg_match('/(^|\s)auto_increment(\s|$)/i', $extra)) {
141 $field['auto_increment'] = true;
143 // $row['EXTRA'] may contain 'on update CURRENT_TIMESTAMP'
144 // ^ ...... how to specify?
147 if ($row['CHARACTER_SET_NAME'] !== null) {
148 // @fixme check against defaults?
149 //$def['charset'] = $row['CHARACTER_SET_NAME'];
150 //$def['collate'] = $row['COLLATION_NAME'];
153 $def['fields'][$name] = $field;
157 // INFORMATION_SCHEMA's CONSTRAINTS and KEY_COLUMN_USAGE tables give
158 // good info on primary and unique keys but don't list ANY info on
159 // multi-value keys, which is lame-o. Sigh.
161 // Let's go old school and use SHOW INDEX :D
163 $keyInfo = $this->fetchIndexInfo($table);
165 foreach ($keyInfo as $row) {
166 $name = $row['Key_name'];
167 $column = $row['Column_name'];
169 if (!isset($keys[$name])) {
170 $keys[$name] = array();
172 $keys[$name][] = $column;
174 if ($name == 'PRIMARY') {
175 $type = 'primary key';
176 } else if ($row['Non_unique'] == 0) {
177 $type = 'unique keys';
178 } else if ($row['Index_type'] == 'FULLTEXT') {
179 $type = 'fulltext indexes';
183 $keyTypes[$name] = $type;
186 foreach ($keyTypes as $name => $type) {
187 if ($type == 'primary key') {
188 // there can be only one
189 $def[$type] = $keys[$name];
191 $def[$type][$name] = $keys[$name];
199 * Pull the given table properties from INFORMATION_SCHEMA.
200 * Most of the good stuff is MySQL extensions.
203 * @throws Exception if table info can't be looked up
206 function getTableProperties($table, $props)
208 $data = $this->fetchMetaInfo($table, 'TABLES');
212 throw new SchemaTableMissingException("No such table: $table");
217 * Pull some INFORMATION.SCHEMA data for the given table.
219 * @param string $table
220 * @return array of arrays
222 function fetchMetaInfo($table, $infoTable, $orderBy=null)
224 $query = "SELECT * FROM INFORMATION_SCHEMA.%s " .
225 "WHERE TABLE_SCHEMA='%s' AND TABLE_NAME='%s'";
226 $schema = $this->conn->dsn['database'];
227 $sql = sprintf($query, $infoTable, $schema, $table);
229 $sql .= ' ORDER BY ' . $orderBy;
231 return $this->fetchQueryData($sql);
235 * Pull 'SHOW INDEX' data for the given table.
237 * @param string $table
238 * @return array of arrays
240 function fetchIndexInfo($table)
242 $query = "SHOW INDEX FROM `%s`";
243 $sql = sprintf($query, $table);
244 return $this->fetchQueryData($sql);
248 * Append an SQL statement with an index definition for a full-text search
249 * index over one or more columns on a table.
251 * @param array $statements
252 * @param string $table
253 * @param string $name
256 function appendCreateFulltextIndex(array &$statements, $table, $name, array $def)
258 $statements[] = "CREATE FULLTEXT INDEX $name ON $table " . $this->buildIndexList($def);
262 * Close out a 'create table' SQL statement.
264 * @param string $name
268 * @fixme ENGINE may need to be set differently in some cases,
269 * such as to support fulltext index.
271 function endCreateTable($name, array $def)
273 $engine = $this->preferredEngine($def);
274 return ") ENGINE=$engine CHARACTER SET utf8 COLLATE utf8_bin";
277 function preferredEngine($def)
279 if (!empty($def['fulltext indexes'])) {
286 * Get the unique index key name for a given column on this table
288 function _uniqueKey($tableName, $columnName)
290 return $this->_key($tableName, $columnName);
294 * Get the index key name for a given column on this table
296 function _key($tableName, $columnName)
298 return "{$tableName}_{$columnName}_idx";
303 * MySQL doesn't take 'DROP CONSTRAINT', need to treat unique keys as
304 * if they were indexes here.
306 * @param array $phrase
307 * @param <type> $keyName MySQL
309 function appendAlterDropUnique(array &$phrase, $keyName)
311 $phrase[] = 'DROP INDEX ' . $keyName;
315 * Throw some table metadata onto the ALTER TABLE if we have a mismatch
316 * in expected type, collation.
318 function appendAlterExtras(array &$phrase, $tableName, array $def)
320 // Check for table properties: make sure we're using a sane
321 // engine type and charset/collation.
322 // @fixme make the default engine configurable?
323 $oldProps = $this->getTableProperties($tableName, array('ENGINE', 'TABLE_COLLATION'));
324 $engine = $this->preferredEngine($def);
325 if (strtolower($oldProps['ENGINE']) != strtolower($engine)) {
326 $phrase[] = "ENGINE=$engine";
328 if (strtolower($oldProps['TABLE_COLLATION']) != 'utf8_bin') {
329 $phrase[] = 'DEFAULT CHARSET=utf8';
330 $phrase[] = 'COLLATE=utf8_bin';
335 * Is this column a string type?
337 private function _isString(array $cd)
339 $strings = array('char', 'varchar', 'text');
340 return in_array(strtolower($cd['type']), $strings);
344 * Return the proper SQL for creating or
347 * Appropriate for use in CREATE TABLE or
348 * ALTER TABLE statements.
350 * @param ColumnDef $cd column to create
352 * @return string correct SQL for that column
355 function columnSql(array $cd)
358 $line[] = parent::columnSql($cd);
360 // This'll have been added from our transform of 'serial' type
361 if (!empty($cd['auto_increment'])) {
362 $line[] = 'auto_increment';
365 if (!empty($cd['description'])) {
367 $line[] = $this->quoteValue($cd['description']);
370 return implode(' ', $line);
373 function mapType($column)
375 $map = array('serial' => 'int',
377 'numeric' => 'decimal');
379 $type = $column['type'];
380 if (isset($map[$type])) {
384 if (!empty($column['size'])) {
385 $size = $column['size'];
386 if ($type == 'int' &&
387 in_array($size, array('tiny', 'small', 'medium', 'big'))) {
388 $type = $size . $type;
389 } else if (in_array($type, array('blob', 'text')) &&
390 in_array($size, array('tiny', 'medium', 'long'))) {
391 $type = $size . $type;
398 function typeAndSize($column)
400 if ($column['type'] == 'enum') {
401 $vals = array_map(array($this, 'quote'), $column['enum']);
402 return 'enum(' . implode(',', $vals) . ')';
403 } else if ($this->_isString($column)) {
404 $col = parent::typeAndSize($column);
405 if (!empty($column['charset'])) {
406 $col .= ' CHARSET ' . $column['charset'];
408 if (!empty($column['collate'])) {
409 $col .= ' COLLATE ' . $column['collate'];
413 return parent::typeAndSize($column);
418 * Filter the given table definition array to match features available
421 * This lets us strip out unsupported things like comments, foreign keys,
422 * or type variants that we wouldn't get back from getTableDef().
424 * @param array $tableDef
426 function filterDef(array $tableDef)
428 foreach ($tableDef['fields'] as $name => &$col) {
429 if ($col['type'] == 'serial') {
430 $col['type'] = 'int';
431 $col['auto_increment'] = true;
433 if ($col['type'] == 'datetime' && isset($col['default']) && $col['default'] == 'CURRENT_TIMESTAMP') {
434 $col['type'] = 'timestamp';
436 $col['type'] = $this->mapType($col);
439 if (!common_config('db', 'mysql_foreign_keys')) {
440 unset($tableDef['foreign keys']);