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 * @author Brenda Wallace <shiny@cpan.org>
45 * @author Brion Vibber <brion@status.net>
46 * @license http://www.fsf.org/licensing/licenses/agpl-3.0.html GNU Affero General Public License version 3.0
47 * @link http://status.net/
50 class PgsqlSchema extends Schema
54 * Returns a table definition array for the table
55 * in the schema with the given name.
57 * Throws an exception if the table is not found.
59 * @param string $table Name of the table to get
61 * @return array tabledef for that table.
64 public function getTableDef($table)
69 // Pull column data from INFORMATION_SCHEMA
70 $columns = $this->fetchMetaInfo($table, 'columns', 'ordinal_position');
71 if (count($columns) == 0) {
72 throw new SchemaTableMissingException("No such table: $table");
75 // We'll need to match up fields by ordinal reference
76 $orderedFields = array();
78 foreach ($columns as $row) {
80 $name = $row['column_name'];
81 $orderedFields[$row['ordinal_position']] = $name;
84 $field['type'] = $row['udt_name'];
86 if ($type == 'char' || $type == 'varchar') {
87 if ($row['character_maximum_length'] !== null) {
88 $field['length'] = intval($row['character_maximum_length']);
91 if ($type == 'numeric') {
92 // Other int types may report these values, but they're irrelevant.
94 if ($row['numeric_precision'] !== null) {
95 $field['precision'] = intval($row['numeric_precision']);
97 if ($row['numeric_scale'] !== null) {
98 $field['scale'] = intval($row['numeric_scale']);
101 if ($row['is_nullable'] == 'NO') {
102 $field['not null'] = true;
104 if ($row['column_default'] !== null) {
105 $field['default'] = $row['column_default'];
106 if ($this->isNumericType($type)) {
107 $field['default'] = intval($field['default']);
111 $def['fields'][$name] = $field;
114 // Pulling index info from pg_class & pg_index
115 // This can give us primary & unique key info, but not foreign key constraints
116 // so we exclude them and pick them up later.
117 $indexInfo = $this->getIndexInfo($table);
118 foreach ($indexInfo as $row) {
119 $keyName = $row['key_name'];
121 // Dig the column references out!
123 // These are inconvenient arrays with partial references to the
124 // pg_att table, but since we've already fetched up the column
125 // info on the current table, we can look those up locally.
127 $colPositions = explode(' ', $row['indkey']);
128 foreach ($colPositions as $ord) {
130 $cols[] = 'FUNCTION'; // @fixme
132 $cols[] = $orderedFields[$ord];
136 $def['indexes'][$keyName] = $cols;
139 // Pull constraint data from INFORMATION_SCHEMA:
140 // Primary key, unique keys, foreign keys
141 $keyColumns = $this->fetchMetaInfo($table, 'key_column_usage', 'constraint_name,ordinal_position');
144 foreach ($keyColumns as $row) {
145 $keyName = $row['constraint_name'];
146 $keyCol = $row['column_name'];
147 if (!isset($keys[$keyName])) {
148 $keys[$keyName] = array();
150 $keys[$keyName][] = $keyCol;
153 foreach ($keys as $keyName => $cols) {
154 // name hack -- is this reliable?
155 if ($keyName == "{$table}_pkey") {
156 $def['primary key'] = $cols;
157 } else if (preg_match("/^{$table}_(.*)_fkey$/", $keyName, $matches)) {
158 $fkey = $this->getForeignKeyInfo($table, $keyName);
159 $colMap = array_combine($cols, $fkey['col_names']);
160 $def['foreign keys'][$keyName] = array($fkey['table_name'], $colMap);
162 $def['unique keys'][$keyName] = $cols;
169 * Pull some INFORMATION.SCHEMA data for the given table.
171 * @param string $table
172 * @return array of arrays
174 function fetchMetaInfo($table, $infoTable, $orderBy=null)
176 $query = "SELECT * FROM information_schema.%s " .
177 "WHERE table_name='%s'";
178 $sql = sprintf($query, $infoTable, $table);
180 $sql .= ' ORDER BY ' . $orderBy;
182 return $this->fetchQueryData($sql);
186 * Pull some PG-specific index info
187 * @param string $table
188 * @return array of arrays
190 function getIndexInfo($table)
193 '(SELECT relname FROM pg_class WHERE oid=indexrelid) AS key_name, ' .
195 'WHERE indrelid=(SELECT oid FROM pg_class WHERE relname=\'%s\') ' .
196 'AND indisprimary=\'f\' AND indisunique=\'f\' ' .
197 'ORDER BY indrelid, indexrelid';
198 $sql = sprintf($query, $table);
199 return $this->fetchQueryData($sql);
203 * Column names from the foreign table can be resolved with a call to getTableColumnNames()
204 * @param <type> $table
205 * @return array array of rows with keys: fkey_name, table_name, table_id, col_names (array of strings)
207 function getForeignKeyInfo($table, $constraint_name)
209 // In a sane world, it'd be easier to query the column names directly.
210 // But it's pretty hard to work with arrays such as col_indexes in direct SQL here.
212 '(SELECT relname FROM pg_class WHERE oid=confrelid) AS table_name, ' .
213 'confrelid AS table_id, ' .
214 '(SELECT indkey FROM pg_index WHERE indexrelid=conindid) AS col_indexes ' .
215 'FROM pg_constraint ' .
216 'WHERE conrelid=(SELECT oid FROM pg_class WHERE relname=\'%s\') ' .
217 'AND conname=\'%s\' ' .
219 $sql = sprintf($query, $table, $constraint_name);
220 $data = $this->fetchQueryData($sql);
221 if (count($data) < 1) {
222 throw new Exception("Could not find foreign key " . $constraint_name . " on table " . $table);
227 'table_name' => $row['table_name'],
228 'col_names' => $this->getTableColumnNames($row['table_id'], $row['col_indexes'])
234 * @param int $table_id
235 * @param array $col_indexes
236 * @return array of strings
238 function getTableColumnNames($table_id, $col_indexes)
240 $indexes = array_map('intval', explode(' ', $col_indexes));
241 $query = 'SELECT attnum AS col_index, attname AS col_name ' .
242 'FROM pg_attribute where attrelid=%d ' .
243 'AND attnum IN (%s)';
244 $sql = sprintf($query, $table_id, implode(',', $indexes));
245 $data = $this->fetchQueryData($sql);
248 foreach ($data as $row) {
249 $byId[$row['col_index']] = $row['col_name'];
253 foreach ($indexes as $id) {
260 * Translate the (mostly) mysql-ish column types into somethings more standard
261 * @param string column type
263 * @return string postgres happy column type
265 private function _columnTypeTranslation($type) {
267 'datetime' => 'timestamp',
269 if(!empty($map[$type])) {
276 * Return the proper SQL for creating or
279 * Appropriate for use in CREATE TABLE or
280 * ALTER TABLE statements.
282 * @param array $cd column to create
284 * @return string correct SQL for that column
287 function columnSql(array $cd)
290 $line[] = parent::columnSql($cd);
293 if ($table['foreign keys'][$name]) {
294 foreach ($table['foreign keys'][$name] as $foreignTable => $foreignColumn) {
295 $line[] = 'references';
296 $line[] = $this->quoteIdentifier($foreignTable);
297 $line[] = '(' . $this->quoteIdentifier($foreignColumn) . ')';
302 return implode(' ', $line);
306 * Append phrase(s) to an array of partial ALTER TABLE chunks in order
307 * to alter the given column from its old state to a new one.
309 * @param array $phrase
310 * @param string $columnName
311 * @param array $old previous column definition as found in DB
312 * @param array $cd current column definition
314 function appendAlterModifyColumn(array &$phrase, $columnName, array $old, array $cd)
316 $prefix = 'ALTER COLUMN ' . $this->quoteIdentifier($columnName) . ' ';
318 $oldType = $this->mapType($old);
319 $newType = $this->mapType($cd);
320 if ($oldType != $newType) {
321 $phrase[] = $prefix . 'TYPE ' . $newType;
324 if (!empty($old['not null']) && empty($cd['not null'])) {
325 $phrase[] = $prefix . 'DROP NOT NULL';
326 } else if (empty($old['not null']) && !empty($cd['not null'])) {
327 $phrase[] = $prefix . 'SET NOT NULL';
330 if (isset($old['default']) && !isset($cd['default'])) {
331 $phrase[] = $prefix . 'DROP DEFAULT';
332 } else if (!isset($old['default']) && isset($cd['default'])) {
333 $phrase[] = $prefix . 'SET DEFAULT ' . $this->quoteDefaultValue($cd);
338 * Append an SQL statement to drop an index from a table.
339 * Note that in PostgreSQL, index names are DB-unique.
341 * @param array $statements
342 * @param string $table
343 * @param string $name
346 function appendDropIndex(array &$statements, $table, $name)
348 $statements[] = "DROP INDEX $name";
352 * Quote a db/table/column identifier if necessary.
354 * @param string $name
357 function quoteIdentifier($name)
359 return $this->conn->quoteIdentifier($name);
362 function mapType($column)
364 $map = array('serial' => 'bigserial', // FIXME: creates the wrong name for the sequence for some internal sequence-lookup function, so better fix this to do the real 'create sequence' dance.
365 'numeric' => 'decimal',
366 'datetime' => 'timestamp',
369 $type = $column['type'];
370 if (isset($map[$type])) {
374 if ($type == 'int') {
375 if (!empty($column['size'])) {
376 $size = $column['size'];
377 if ($size == 'small') {
379 } else if ($size == 'big') {
389 // @fixme need name... :P
390 function typeAndSize($column)
392 if ($column['type'] == 'enum') {
393 $vals = array_map(array($this, 'quote'), $column['enum']);
394 return "text check ($name in " . implode(',', $vals) . ')';
396 return parent::typeAndSize($column);
401 * Filter the given table definition array to match features available
404 * This lets us strip out unsupported things like comments, foreign keys,
405 * or type variants that we wouldn't get back from getTableDef().
407 * @param array $tableDef
409 function filterDef(array $tableDef)
411 foreach ($tableDef['fields'] as $name => &$col) {
412 // No convenient support for field descriptions
413 unset($col['description']);
416 if (isset($col['size'])) {
417 // Don't distinguish between tinyint and int.
418 if ($col['size'] == 'tiny' && $col['type'] == 'int') {
423 $col['type'] = $this->mapType($col);
426 if (!empty($tableDef['primary key'])) {
427 $tableDef['primary key'] = $this->filterKeyDef($tableDef['primary key']);
429 if (!empty($tableDef['unique keys'])) {
430 foreach ($tableDef['unique keys'] as $i => $def) {
431 $tableDef['unique keys'][$i] = $this->filterKeyDef($def);
438 * Filter the given key/index definition to match features available
444 function filterKeyDef(array $def)
446 // PostgreSQL doesn't like prefix lengths specified on keys...?
447 foreach ($def as $i => $item)
449 if (is_array($item)) {