pgsqlschema.php 15 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457
  1. <?php
  2. // This file is part of GNU social - https://www.gnu.org/software/social
  3. //
  4. // GNU social is free software: you can redistribute it and/or modify
  5. // it under the terms of the GNU Affero General Public License as published by
  6. // the Free Software Foundation, either version 3 of the License, or
  7. // (at your option) any later version.
  8. //
  9. // GNU social is distributed in the hope that it will be useful,
  10. // but WITHOUT ANY WARRANTY; without even the implied warranty of
  11. // MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
  12. // GNU Affero General Public License for more details.
  13. //
  14. // You should have received a copy of the GNU Affero General Public License
  15. // along with GNU social. If not, see <http://www.gnu.org/licenses/>.
  16. /**
  17. * Database schema for PostgreSQL
  18. *
  19. * @category Database
  20. * @package GNUsocial
  21. * @author Evan Prodromou <evan@status.net>
  22. * @author Brenda Wallace <shiny@cpan.org>
  23. * @author Brion Vibber <brion@status.net>
  24. * @copyright 2019 Free Software Foundation, Inc http://www.fsf.org
  25. * @license https://www.gnu.org/licenses/agpl.html GNU AGPL v3 or later
  26. */
  27. defined('GNUSOCIAL') || die();
  28. /**
  29. * Class representing the database schema for PostgreSQL
  30. *
  31. * A class representing the database schema. Can be used to
  32. * manipulate the schema -- especially for plugins and upgrade
  33. * utilities.
  34. *
  35. * @copyright 2019 Free Software Foundation, Inc http://www.fsf.org
  36. * @license https://www.gnu.org/licenses/agpl.html GNU AGPL v3 or later
  37. */
  38. class PgsqlSchema extends Schema
  39. {
  40. /**
  41. * Returns a table definition array for the table
  42. * in the schema with the given name.
  43. *
  44. * Throws an exception if the table is not found.
  45. *
  46. * @param string $table Name of the table to get
  47. *
  48. * @return array tabledef for that table.
  49. * @throws SchemaTableMissingException
  50. */
  51. public function getTableDef($table)
  52. {
  53. $def = [];
  54. $hasKeys = false;
  55. // Pull column data from INFORMATION_SCHEMA
  56. $columns = $this->fetchMetaInfo($table, 'columns', 'ordinal_position');
  57. if (count($columns) == 0) {
  58. throw new SchemaTableMissingException("No such table: $table");
  59. }
  60. // We'll need to match up fields by ordinal reference
  61. $orderedFields = [];
  62. foreach ($columns as $row) {
  63. $name = $row['column_name'];
  64. $orderedFields[$row['ordinal_position']] = $name;
  65. $field = [];
  66. $field['type'] = $type = $row['udt_name'];
  67. if ($type == 'char' || $type == 'varchar') {
  68. if ($row['character_maximum_length'] !== null) {
  69. $field['length'] = intval($row['character_maximum_length']);
  70. }
  71. }
  72. if ($type == 'numeric') {
  73. // Other int types may report these values, but they're irrelevant.
  74. // Just ignore them!
  75. if ($row['numeric_precision'] !== null) {
  76. $field['precision'] = intval($row['numeric_precision']);
  77. }
  78. if ($row['numeric_scale'] !== null) {
  79. $field['scale'] = intval($row['numeric_scale']);
  80. }
  81. }
  82. if ($row['is_nullable'] == 'NO') {
  83. $field['not null'] = true;
  84. }
  85. if ($row['column_default'] !== null) {
  86. $field['default'] = $row['column_default'];
  87. if ($this->isNumericType($type)) {
  88. $field['default'] = intval($field['default']);
  89. }
  90. }
  91. $def['fields'][$name] = $field;
  92. }
  93. // Pulling index info from pg_class & pg_index
  94. // This can give us primary & unique key info, but not foreign key constraints
  95. // so we exclude them and pick them up later.
  96. $indexInfo = $this->getIndexInfo($table);
  97. foreach ($indexInfo as $row) {
  98. $keyName = $row['key_name'];
  99. // Dig the column references out!
  100. //
  101. // These are inconvenient arrays with partial references to the
  102. // pg_att table, but since we've already fetched up the column
  103. // info on the current table, we can look those up locally.
  104. $cols = [];
  105. $colPositions = explode(' ', $row['indkey']);
  106. foreach ($colPositions as $ord) {
  107. if ($ord == 0) {
  108. $cols[] = 'FUNCTION'; // @fixme
  109. } else {
  110. $cols[] = $orderedFields[$ord];
  111. }
  112. }
  113. $def['indexes'][$keyName] = $cols;
  114. }
  115. // Pull constraint data from INFORMATION_SCHEMA:
  116. // Primary key, unique keys, foreign keys
  117. $keyColumns = $this->fetchMetaInfo($table, 'key_column_usage', 'constraint_name,ordinal_position');
  118. $keys = [];
  119. foreach ($keyColumns as $row) {
  120. $keyName = $row['constraint_name'];
  121. $keyCol = $row['column_name'];
  122. if (!isset($keys[$keyName])) {
  123. $keys[$keyName] = [];
  124. }
  125. $keys[$keyName][] = $keyCol;
  126. }
  127. foreach ($keys as $keyName => $cols) {
  128. // name hack -- is this reliable?
  129. if ($keyName == "{$table}_pkey") {
  130. $def['primary key'] = $cols;
  131. } else if (preg_match("/^{$table}_(.*)_fkey$/", $keyName, $matches)) {
  132. $fkey = $this->getForeignKeyInfo($table, $keyName);
  133. $colMap = array_combine($cols, $fkey['col_names']);
  134. $def['foreign keys'][$keyName] = [$fkey['table_name'], $colMap];
  135. } else {
  136. $def['unique keys'][$keyName] = $cols;
  137. }
  138. }
  139. return $def;
  140. }
  141. /**
  142. * Pull some INFORMATION.SCHEMA data for the given table.
  143. *
  144. * @param string $table
  145. * @param $infoTable
  146. * @param null $orderBy
  147. * @return array of arrays
  148. * @throws PEAR_Exception
  149. */
  150. function fetchMetaInfo($table, $infoTable, $orderBy = null)
  151. {
  152. $query = "SELECT * FROM information_schema.%s " .
  153. "WHERE table_name='%s'";
  154. $sql = sprintf($query, $infoTable, $table);
  155. if ($orderBy) {
  156. $sql .= ' ORDER BY ' . $orderBy;
  157. }
  158. return $this->fetchQueryData($sql);
  159. }
  160. /**
  161. * Pull some PG-specific index info
  162. * @param string $table
  163. * @return array of arrays
  164. * @throws PEAR_Exception
  165. */
  166. function getIndexInfo($table)
  167. {
  168. $query = 'SELECT ' .
  169. '(SELECT relname FROM pg_class WHERE oid=indexrelid) AS key_name, ' .
  170. '* FROM pg_index ' .
  171. 'WHERE indrelid=(SELECT oid FROM pg_class WHERE relname=\'%s\') ' .
  172. 'AND indisprimary=\'f\' AND indisunique=\'f\' ' .
  173. 'ORDER BY indrelid, indexrelid';
  174. $sql = sprintf($query, $table);
  175. return $this->fetchQueryData($sql);
  176. }
  177. /**
  178. * Column names from the foreign table can be resolved with a call to getTableColumnNames()
  179. * @param string $table
  180. * @param $constraint_name
  181. * @return array array of rows with keys: fkey_name, table_name, table_id, col_names (array of strings)
  182. * @throws PEAR_Exception
  183. */
  184. function getForeignKeyInfo($table, $constraint_name)
  185. {
  186. // In a sane world, it'd be easier to query the column names directly.
  187. // But it's pretty hard to work with arrays such as col_indexes in direct SQL here.
  188. $query = 'SELECT ' .
  189. '(SELECT relname FROM pg_class WHERE oid=confrelid) AS table_name, ' .
  190. 'confrelid AS table_id, ' .
  191. '(SELECT indkey FROM pg_index WHERE indexrelid=conindid) AS col_indexes ' .
  192. 'FROM pg_constraint ' .
  193. 'WHERE conrelid=(SELECT oid FROM pg_class WHERE relname=\'%s\') ' .
  194. 'AND conname=\'%s\' ' .
  195. 'AND contype=\'f\'';
  196. $sql = sprintf($query, $table, $constraint_name);
  197. $data = $this->fetchQueryData($sql);
  198. if (count($data) < 1) {
  199. throw new Exception("Could not find foreign key " . $constraint_name . " on table " . $table);
  200. }
  201. $row = $data[0];
  202. return [
  203. 'table_name' => $row['table_name'],
  204. 'col_names' => $this->getTableColumnNames($row['table_id'], $row['col_indexes'])
  205. ];
  206. }
  207. /**
  208. *
  209. * @param int $table_id
  210. * @param array $col_indexes
  211. * @return array of strings
  212. * @throws PEAR_Exception
  213. */
  214. function getTableColumnNames($table_id, $col_indexes)
  215. {
  216. $indexes = array_map('intval', explode(' ', $col_indexes));
  217. $query = 'SELECT attnum AS col_index, attname AS col_name ' .
  218. 'FROM pg_attribute where attrelid=%d ' .
  219. 'AND attnum IN (%s)';
  220. $sql = sprintf($query, $table_id, implode(',', $indexes));
  221. $data = $this->fetchQueryData($sql);
  222. $byId = [];
  223. foreach ($data as $row) {
  224. $byId[$row['col_index']] = $row['col_name'];
  225. }
  226. $out = [];
  227. foreach ($indexes as $id) {
  228. $out[] = $byId[$id];
  229. }
  230. return $out;
  231. }
  232. /**
  233. * Translate the (mostly) mysql-ish column types into somethings more standard
  234. * @param string column type
  235. *
  236. * @return string postgres happy column type
  237. */
  238. private function _columnTypeTranslation($type)
  239. {
  240. $map = [
  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 = [];
  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. */
  310. function appendDropIndex(array &$statements, $table, $name)
  311. {
  312. $statements[] = "DROP INDEX $name";
  313. }
  314. /**
  315. * Quote a db/table/column identifier if necessary.
  316. *
  317. * @param string $name
  318. * @return string
  319. */
  320. function quoteIdentifier($name)
  321. {
  322. return $this->conn->quoteIdentifier($name);
  323. }
  324. function mapType($column)
  325. {
  326. $map = [
  327. '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. ];
  332. $type = $column['type'];
  333. if (isset($map[$type])) {
  334. $type = $map[$type];
  335. }
  336. if ($type == 'int') {
  337. if (!empty($column['size'])) {
  338. $size = $column['size'];
  339. if ($size == 'small') {
  340. return 'int2';
  341. } else if ($size == 'big') {
  342. return 'int8';
  343. }
  344. }
  345. return 'int4';
  346. }
  347. return $type;
  348. }
  349. // @fixme need name... :P
  350. function typeAndSize($column)
  351. {
  352. if ($column['type'] == 'enum') {
  353. $vals = array_map([$this, 'quote'], $column['enum']);
  354. return "text check ($name in " . implode(',', $vals) . ')';
  355. } else {
  356. return parent::typeAndSize($column);
  357. }
  358. }
  359. /**
  360. * Filter the given table definition array to match features available
  361. * in this database.
  362. *
  363. * This lets us strip out unsupported things like comments, foreign keys,
  364. * or type variants that we wouldn't get back from getTableDef().
  365. *
  366. * @param array $tableDef
  367. * @return array
  368. */
  369. function filterDef(array $tableDef)
  370. {
  371. foreach ($tableDef['fields'] as $name => &$col) {
  372. // No convenient support for field descriptions
  373. unset($col['description']);
  374. /*
  375. if (isset($col['size'])) {
  376. // Don't distinguish between tinyint and int.
  377. if ($col['size'] == 'tiny' && $col['type'] == 'int') {
  378. unset($col['size']);
  379. }
  380. }
  381. */
  382. $col['type'] = $this->mapType($col);
  383. unset($col['size']);
  384. }
  385. if (!empty($tableDef['primary key'])) {
  386. $tableDef['primary key'] = $this->filterKeyDef($tableDef['primary key']);
  387. }
  388. if (!empty($tableDef['unique keys'])) {
  389. foreach ($tableDef['unique keys'] as $i => $def) {
  390. $tableDef['unique keys'][$i] = $this->filterKeyDef($def);
  391. }
  392. }
  393. return $tableDef;
  394. }
  395. /**
  396. * Filter the given key/index definition to match features available
  397. * in this database.
  398. *
  399. * @param array $def
  400. * @return array
  401. */
  402. function filterKeyDef(array $def)
  403. {
  404. // PostgreSQL doesn't like prefix lengths specified on keys...?
  405. foreach ($def as $i => $item) {
  406. if (is_array($item)) {
  407. $def[$i] = $item[0];
  408. }
  409. }
  410. return $def;
  411. }
  412. }