pgsqlschema.php 15 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456
  1. <?php
  2. /**
  3. * StatusNet, the distributed open-source microblogging tool
  4. *
  5. * Database schema utilities
  6. *
  7. * PHP version 5
  8. *
  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.
  13. *
  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.
  18. *
  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/>.
  21. *
  22. * @category Database
  23. * @package StatusNet
  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/
  28. */
  29. if (!defined('STATUSNET')) {
  30. exit(1);
  31. }
  32. /**
  33. * Class representing the database schema
  34. *
  35. * A class representing the database schema. Can be used to
  36. * manipulate the schema -- especially for plugins and upgrade
  37. * utilities.
  38. *
  39. * @category Database
  40. * @package StatusNet
  41. * @author Evan Prodromou <evan@status.net>
  42. * @author Brenda Wallace <shiny@cpan.org>
  43. * @author Brion Vibber <brion@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/
  46. */
  47. class PgsqlSchema extends Schema
  48. {
  49. /**
  50. * Returns a table definition array for the table
  51. * in the schema with the given name.
  52. *
  53. * Throws an exception if the table is not found.
  54. *
  55. * @param string $table Name of the table to get
  56. *
  57. * @return array tabledef for that table.
  58. */
  59. public function getTableDef($table)
  60. {
  61. $def = array();
  62. $hasKeys = false;
  63. // Pull column data from INFORMATION_SCHEMA
  64. $columns = $this->fetchMetaInfo($table, 'columns', 'ordinal_position');
  65. if (count($columns) == 0) {
  66. throw new SchemaTableMissingException("No such table: $table");
  67. }
  68. // We'll need to match up fields by ordinal reference
  69. $orderedFields = array();
  70. foreach ($columns as $row) {
  71. $name = $row['column_name'];
  72. $orderedFields[$row['ordinal_position']] = $name;
  73. $field = array();
  74. $field['type'] = $row['udt_name'];
  75. if ($type == 'char' || $type == 'varchar') {
  76. if ($row['character_maximum_length'] !== null) {
  77. $field['length'] = intval($row['character_maximum_length']);
  78. }
  79. }
  80. if ($type == 'numeric') {
  81. // Other int types may report these values, but they're irrelevant.
  82. // Just ignore them!
  83. if ($row['numeric_precision'] !== null) {
  84. $field['precision'] = intval($row['numeric_precision']);
  85. }
  86. if ($row['numeric_scale'] !== null) {
  87. $field['scale'] = intval($row['numeric_scale']);
  88. }
  89. }
  90. if ($row['is_nullable'] == 'NO') {
  91. $field['not null'] = true;
  92. }
  93. if ($row['column_default'] !== null) {
  94. $field['default'] = $row['column_default'];
  95. if ($this->isNumericType($type)) {
  96. $field['default'] = intval($field['default']);
  97. }
  98. }
  99. $def['fields'][$name] = $field;
  100. }
  101. // Pulling index info from pg_class & pg_index
  102. // This can give us primary & unique key info, but not foreign key constraints
  103. // so we exclude them and pick them up later.
  104. $indexInfo = $this->getIndexInfo($table);
  105. foreach ($indexInfo as $row) {
  106. $keyName = $row['key_name'];
  107. // Dig the column references out!
  108. //
  109. // These are inconvenient arrays with partial references to the
  110. // pg_att table, but since we've already fetched up the column
  111. // info on the current table, we can look those up locally.
  112. $cols = array();
  113. $colPositions = explode(' ', $row['indkey']);
  114. foreach ($colPositions as $ord) {
  115. if ($ord == 0) {
  116. $cols[] = 'FUNCTION'; // @fixme
  117. } else {
  118. $cols[] = $orderedFields[$ord];
  119. }
  120. }
  121. $def['indexes'][$keyName] = $cols;
  122. }
  123. // Pull constraint data from INFORMATION_SCHEMA:
  124. // Primary key, unique keys, foreign keys
  125. $keyColumns = $this->fetchMetaInfo($table, 'key_column_usage', 'constraint_name,ordinal_position');
  126. $keys = array();
  127. foreach ($keyColumns as $row) {
  128. $keyName = $row['constraint_name'];
  129. $keyCol = $row['column_name'];
  130. if (!isset($keys[$keyName])) {
  131. $keys[$keyName] = array();
  132. }
  133. $keys[$keyName][] = $keyCol;
  134. }
  135. foreach ($keys as $keyName => $cols) {
  136. // name hack -- is this reliable?
  137. if ($keyName == "{$table}_pkey") {
  138. $def['primary key'] = $cols;
  139. } else if (preg_match("/^{$table}_(.*)_fkey$/", $keyName, $matches)) {
  140. $fkey = $this->getForeignKeyInfo($table, $keyName);
  141. $colMap = array_combine($cols, $fkey['col_names']);
  142. $def['foreign keys'][$keyName] = array($fkey['table_name'], $colMap);
  143. } else {
  144. $def['unique keys'][$keyName] = $cols;
  145. }
  146. }
  147. return $def;
  148. }
  149. /**
  150. * Pull some INFORMATION.SCHEMA data for the given table.
  151. *
  152. * @param string $table
  153. * @return array of arrays
  154. */
  155. function fetchMetaInfo($table, $infoTable, $orderBy=null)
  156. {
  157. $query = "SELECT * FROM information_schema.%s " .
  158. "WHERE table_name='%s'";
  159. $sql = sprintf($query, $infoTable, $table);
  160. if ($orderBy) {
  161. $sql .= ' ORDER BY ' . $orderBy;
  162. }
  163. return $this->fetchQueryData($sql);
  164. }
  165. /**
  166. * Pull some PG-specific index info
  167. * @param string $table
  168. * @return array of arrays
  169. */
  170. function getIndexInfo($table)
  171. {
  172. $query = 'SELECT ' .
  173. '(SELECT relname FROM pg_class WHERE oid=indexrelid) AS key_name, ' .
  174. '* FROM pg_index ' .
  175. 'WHERE indrelid=(SELECT oid FROM pg_class WHERE relname=\'%s\') ' .
  176. 'AND indisprimary=\'f\' AND indisunique=\'f\' ' .
  177. 'ORDER BY indrelid, indexrelid';
  178. $sql = sprintf($query, $table);
  179. return $this->fetchQueryData($sql);
  180. }
  181. /**
  182. * Column names from the foreign table can be resolved with a call to getTableColumnNames()
  183. * @param <type> $table
  184. * @return array array of rows with keys: fkey_name, table_name, table_id, col_names (array of strings)
  185. */
  186. function getForeignKeyInfo($table, $constraint_name)
  187. {
  188. // In a sane world, it'd be easier to query the column names directly.
  189. // But it's pretty hard to work with arrays such as col_indexes in direct SQL here.
  190. $query = 'SELECT ' .
  191. '(SELECT relname FROM pg_class WHERE oid=confrelid) AS table_name, ' .
  192. 'confrelid AS table_id, ' .
  193. '(SELECT indkey FROM pg_index WHERE indexrelid=conindid) AS col_indexes ' .
  194. 'FROM pg_constraint ' .
  195. 'WHERE conrelid=(SELECT oid FROM pg_class WHERE relname=\'%s\') ' .
  196. 'AND conname=\'%s\' ' .
  197. 'AND contype=\'f\'';
  198. $sql = sprintf($query, $table, $constraint_name);
  199. $data = $this->fetchQueryData($sql);
  200. if (count($data) < 1) {
  201. throw new Exception("Could not find foreign key " . $constraint_name . " on table " . $table);
  202. }
  203. $row = $data[0];
  204. return array(
  205. 'table_name' => $row['table_name'],
  206. 'col_names' => $this->getTableColumnNames($row['table_id'], $row['col_indexes'])
  207. );
  208. }
  209. /**
  210. *
  211. * @param int $table_id
  212. * @param array $col_indexes
  213. * @return array of strings
  214. */
  215. function getTableColumnNames($table_id, $col_indexes)
  216. {
  217. $indexes = array_map('intval', explode(' ', $col_indexes));
  218. $query = 'SELECT attnum AS col_index, attname AS col_name ' .
  219. 'FROM pg_attribute where attrelid=%d ' .
  220. 'AND attnum IN (%s)';
  221. $sql = sprintf($query, $table_id, implode(',', $indexes));
  222. $data = $this->fetchQueryData($sql);
  223. $byId = array();
  224. foreach ($data as $row) {
  225. $byId[$row['col_index']] = $row['col_name'];
  226. }
  227. $out = array();
  228. foreach ($indexes as $id) {
  229. $out[] = $byId[$id];
  230. }
  231. return $out;
  232. }
  233. /**
  234. * Translate the (mostly) mysql-ish column types into somethings more standard
  235. * @param string column type
  236. *
  237. * @return string postgres happy column type
  238. */
  239. private function _columnTypeTranslation($type) {
  240. $map = array(
  241. 'datetime' => 'timestamp',
  242. );
  243. if(!empty($map[$type])) {
  244. return $map[$type];
  245. }
  246. return $type;
  247. }
  248. /**
  249. * Return the proper SQL for creating or
  250. * altering a column.
  251. *
  252. * Appropriate for use in CREATE TABLE or
  253. * ALTER TABLE statements.
  254. *
  255. * @param array $cd column to create
  256. *
  257. * @return string correct SQL for that column
  258. */
  259. function columnSql(array $cd)
  260. {
  261. $line = array();
  262. $line[] = parent::columnSql($cd);
  263. /*
  264. if ($table['foreign keys'][$name]) {
  265. foreach ($table['foreign keys'][$name] as $foreignTable => $foreignColumn) {
  266. $line[] = 'references';
  267. $line[] = $this->quoteIdentifier($foreignTable);
  268. $line[] = '(' . $this->quoteIdentifier($foreignColumn) . ')';
  269. }
  270. }
  271. */
  272. return implode(' ', $line);
  273. }
  274. /**
  275. * Append phrase(s) to an array of partial ALTER TABLE chunks in order
  276. * to alter the given column from its old state to a new one.
  277. *
  278. * @param array $phrase
  279. * @param string $columnName
  280. * @param array $old previous column definition as found in DB
  281. * @param array $cd current column definition
  282. */
  283. function appendAlterModifyColumn(array &$phrase, $columnName, array $old, array $cd)
  284. {
  285. $prefix = 'ALTER COLUMN ' . $this->quoteIdentifier($columnName) . ' ';
  286. $oldType = $this->mapType($old);
  287. $newType = $this->mapType($cd);
  288. if ($oldType != $newType) {
  289. $phrase[] = $prefix . 'TYPE ' . $newType;
  290. }
  291. if (!empty($old['not null']) && empty($cd['not null'])) {
  292. $phrase[] = $prefix . 'DROP NOT NULL';
  293. } else if (empty($old['not null']) && !empty($cd['not null'])) {
  294. $phrase[] = $prefix . 'SET NOT NULL';
  295. }
  296. if (isset($old['default']) && !isset($cd['default'])) {
  297. $phrase[] = $prefix . 'DROP DEFAULT';
  298. } else if (!isset($old['default']) && isset($cd['default'])) {
  299. $phrase[] = $prefix . 'SET DEFAULT ' . $this->quoteDefaultValue($cd);
  300. }
  301. }
  302. /**
  303. * Append an SQL statement to drop an index from a table.
  304. * Note that in PostgreSQL, index names are DB-unique.
  305. *
  306. * @param array $statements
  307. * @param string $table
  308. * @param string $name
  309. * @param array $def
  310. */
  311. function appendDropIndex(array &$statements, $table, $name)
  312. {
  313. $statements[] = "DROP INDEX $name";
  314. }
  315. /**
  316. * Quote a db/table/column identifier if necessary.
  317. *
  318. * @param string $name
  319. * @return string
  320. */
  321. function quoteIdentifier($name)
  322. {
  323. return $this->conn->quoteIdentifier($name);
  324. }
  325. function mapType($column)
  326. {
  327. $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.
  328. 'numeric' => 'decimal',
  329. 'datetime' => 'timestamp',
  330. 'blob' => 'bytea');
  331. $type = $column['type'];
  332. if (isset($map[$type])) {
  333. $type = $map[$type];
  334. }
  335. if ($type == 'int') {
  336. if (!empty($column['size'])) {
  337. $size = $column['size'];
  338. if ($size == 'small') {
  339. return 'int2';
  340. } else if ($size == 'big') {
  341. return 'int8';
  342. }
  343. }
  344. return 'int4';
  345. }
  346. return $type;
  347. }
  348. // @fixme need name... :P
  349. function typeAndSize($column)
  350. {
  351. if ($column['type'] == 'enum') {
  352. $vals = array_map(array($this, 'quote'), $column['enum']);
  353. return "text check ($name in " . implode(',', $vals) . ')';
  354. } else {
  355. return parent::typeAndSize($column);
  356. }
  357. }
  358. /**
  359. * Filter the given table definition array to match features available
  360. * in this database.
  361. *
  362. * This lets us strip out unsupported things like comments, foreign keys,
  363. * or type variants that we wouldn't get back from getTableDef().
  364. *
  365. * @param array $tableDef
  366. */
  367. function filterDef(array $tableDef)
  368. {
  369. foreach ($tableDef['fields'] as $name => &$col) {
  370. // No convenient support for field descriptions
  371. unset($col['description']);
  372. /*
  373. if (isset($col['size'])) {
  374. // Don't distinguish between tinyint and int.
  375. if ($col['size'] == 'tiny' && $col['type'] == 'int') {
  376. unset($col['size']);
  377. }
  378. }
  379. */
  380. $col['type'] = $this->mapType($col);
  381. unset($col['size']);
  382. }
  383. if (!empty($tableDef['primary key'])) {
  384. $tableDef['primary key'] = $this->filterKeyDef($tableDef['primary key']);
  385. }
  386. if (!empty($tableDef['unique keys'])) {
  387. foreach ($tableDef['unique keys'] as $i => $def) {
  388. $tableDef['unique keys'][$i] = $this->filterKeyDef($def);
  389. }
  390. }
  391. return $tableDef;
  392. }
  393. /**
  394. * Filter the given key/index definition to match features available
  395. * in this database.
  396. *
  397. * @param array $def
  398. * @return array
  399. */
  400. function filterKeyDef(array $def)
  401. {
  402. // PostgreSQL doesn't like prefix lengths specified on keys...?
  403. foreach ($def as $i => $item)
  404. {
  405. if (is_array($item)) {
  406. $def[$i] = $item[0];
  407. }
  408. }
  409. return $def;
  410. }
  411. }