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 $field['default'] = $row['COLUMN_DEFAULT'];
121 if ($this->isNumericType($type)) {
122 $field['default'] = intval($field['default']);
125 if ($row['COLUMN_KEY'] !== null) {
126 // We'll need to look up key info...
129 if ($row['COLUMN_COMMENT'] !== null && $row['COLUMN_COMMENT'] != '') {
130 $field['description'] = $row['COLUMN_COMMENT'];
133 $extra = $row['EXTRA'];
135 if (preg_match('/(^|\s)auto_increment(\s|$)/i', $extra)) {
136 $field['auto_increment'] = true;
138 // $row['EXTRA'] may contain 'on update CURRENT_TIMESTAMP'
139 // ^ ...... how to specify?
142 if ($row['CHARACTER_SET_NAME'] !== null) {
143 // @fixme check against defaults?
144 //$def['charset'] = $row['CHARACTER_SET_NAME'];
145 //$def['collate'] = $row['COLLATION_NAME'];
148 $def['fields'][$name] = $field;
152 // INFORMATION_SCHEMA's CONSTRAINTS and KEY_COLUMN_USAGE tables give
153 // good info on primary and unique keys but don't list ANY info on
154 // multi-value keys, which is lame-o. Sigh.
156 // Let's go old school and use SHOW INDEX :D
158 $keyInfo = $this->fetchIndexInfo($table);
160 foreach ($keyInfo as $row) {
161 $name = $row['Key_name'];
162 $column = $row['Column_name'];
164 if (!isset($keys[$name])) {
165 $keys[$name] = array();
167 $keys[$name][] = $column;
169 if ($name == 'PRIMARY') {
170 $type = 'primary key';
171 } else if ($row['Non_unique'] == 0) {
172 $type = 'unique keys';
173 } else if ($row['Index_type'] == 'FULLTEXT') {
174 $type = 'fulltext indexes';
178 $keyTypes[$name] = $type;
181 foreach ($keyTypes as $name => $type) {
182 if ($type == 'primary key') {
183 // there can be only one
184 $def[$type] = $keys[$name];
186 $def[$type][$name] = $keys[$name];
194 * Pull the given table properties from INFORMATION_SCHEMA.
195 * Most of the good stuff is MySQL extensions.
198 * @throws Exception if table info can't be looked up
201 function getTableProperties($table, $props)
203 $data = $this->fetchMetaInfo($table, 'TABLES');
207 throw new SchemaTableMissingException("No such table: $table");
212 * Pull some INFORMATION.SCHEMA data for the given table.
214 * @param string $table
215 * @return array of arrays
217 function fetchMetaInfo($table, $infoTable, $orderBy=null)
219 $query = "SELECT * FROM INFORMATION_SCHEMA.%s " .
220 "WHERE TABLE_SCHEMA='%s' AND TABLE_NAME='%s'";
221 $schema = $this->conn->dsn['database'];
222 $sql = sprintf($query, $infoTable, $schema, $table);
224 $sql .= ' ORDER BY ' . $orderBy;
226 return $this->fetchQueryData($sql);
230 * Pull 'SHOW INDEX' data for the given table.
232 * @param string $table
233 * @return array of arrays
235 function fetchIndexInfo($table)
237 $query = "SHOW INDEX FROM `%s`";
238 $sql = sprintf($query, $table);
239 return $this->fetchQueryData($sql);
243 * Close out a 'create table' SQL statement.
245 * @param string $name
249 * @fixme ENGINE may need to be set differently in some cases,
250 * such as to support fulltext index.
252 function endCreateTable($name, array $def)
254 return ") ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin";
258 * Get the unique index key name for a given column on this table
260 function _uniqueKey($tableName, $columnName)
262 return $this->_key($tableName, $columnName);
266 * Get the index key name for a given column on this table
268 function _key($tableName, $columnName)
270 return "{$tableName}_{$columnName}_idx";
275 * MySQL doesn't take 'DROP CONSTRAINT', need to treat unique keys as
276 * if they were indexes here.
278 * @param array $phrase
279 * @param <type> $keyName MySQL
281 function appendAlterDropUnique(array &$phrase, $keyName)
283 $phrase[] = 'DROP INDEX ' . $keyName;
287 * Throw some table metadata onto the ALTER TABLE if we have a mismatch
288 * in expected type, collation.
290 function appendAlterExtras(array &$phrase, $tableName)
292 // Check for table properties: make sure we're using a sane
293 // engine type and charset/collation.
294 // @fixme make the default engine configurable?
295 $oldProps = $this->getTableProperties($tableName, array('ENGINE', 'TABLE_COLLATION'));
296 if (strtolower($oldProps['ENGINE']) != 'innodb') {
297 $phrase[] = 'ENGINE=InnoDB';
299 if (strtolower($oldProps['TABLE_COLLATION']) != 'utf8_bin') {
300 $phrase[] = 'DEFAULT CHARSET=utf8';
301 $phrase[] = 'COLLATE=utf8_bin';
306 * Is this column a string type?
308 private function _isString(array $cd)
310 $strings = array('char', 'varchar', 'text');
311 return in_array(strtolower($cd['type']), $strings);
315 * Return the proper SQL for creating or
318 * Appropriate for use in CREATE TABLE or
319 * ALTER TABLE statements.
321 * @param ColumnDef $cd column to create
323 * @return string correct SQL for that column
326 function columnSql(array $cd)
329 $line[] = parent::columnSql($cd);
331 // This'll have been added from our transform of 'serial' type
332 if (!empty($cd['auto_increment'])) {
333 $line[] = 'auto_increment';
336 if (!empty($cd['description'])) {
338 $line[] = $this->quoteValue($cd['description']);
341 return implode(' ', $line);
344 function mapType($column)
346 $map = array('serial' => 'int',
348 'numeric' => 'decimal');
350 $type = $column['type'];
351 if (isset($map[$type])) {
355 if (!empty($column['size'])) {
356 $size = $column['size'];
357 if ($type == 'int' &&
358 in_array($size, array('tiny', 'small', 'medium', 'big'))) {
359 $type = $size . $type;
360 } else if (in_array($type, array('blob', 'text')) &&
361 in_array($size, array('tiny', 'medium', 'long'))) {
362 $type = $size . $type;
369 function typeAndSize($column)
371 if ($column['type'] == 'enum') {
372 $vals = array_map(array($this, 'quote'), $column['enum']);
373 return 'enum(' . implode(',', $vals) . ')';
374 } else if ($this->_isString($column)) {
375 return parent::typeAndSize($column) . ' CHARSET utf8';
377 return parent::typeAndSize($column);
382 * Filter the given table definition array to match features available
385 * This lets us strip out unsupported things like comments, foreign keys,
386 * or type variants that we wouldn't get back from getTableDef().
388 * @param array $tableDef
390 function filterDef(array $tableDef)
392 foreach ($tableDef['fields'] as $name => &$col) {
393 if ($col['type'] == 'serial') {
394 $col['type'] = 'int';
395 $col['auto_increment'] = true;
397 if ($col['type'] == 'datetime' && isset($col['default']) && $col['default'] == 'CURRENT_TIMESTAMP') {
398 $col['type'] = 'timestamp';
400 $col['type'] = $this->mapType($col);
403 if (!common_config('db', 'mysql_foreign_keys')) {
404 unset($tableDef['foreign keys']);