pgsqlschema.php 18 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574
  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. public static $_single = null;
  41. /**
  42. * Main public entry point. Use this to get
  43. * the singleton object.
  44. *
  45. * @param object|null $conn
  46. * @param string|null dummy param
  47. * @return Schema the (single) Schema object
  48. */
  49. public static function get($conn = null, $_ = 'pgsql')
  50. {
  51. if (empty(self::$_single)) {
  52. self::$_single = new Schema($conn, 'pgsql');
  53. }
  54. return self::$_single;
  55. }
  56. /**
  57. * Returns a table definition array for the table
  58. * in the schema with the given name.
  59. *
  60. * Throws an exception if the table is not found.
  61. *
  62. * @param string $table Name of the table to get
  63. *
  64. * @return array tabledef for that table.
  65. * @throws SchemaTableMissingException
  66. */
  67. public function getTableDef($table)
  68. {
  69. $def = [];
  70. $hasKeys = false;
  71. // Pull column data from INFORMATION_SCHEMA
  72. $columns = $this->fetchMetaInfo($table, 'columns', 'ordinal_position');
  73. if (count($columns) == 0) {
  74. throw new SchemaTableMissingException("No such table: $table");
  75. }
  76. // Get information on the emulated "enum" type
  77. $enum_info = $this->fetchEnumInfo($table);
  78. foreach ($columns as $row) {
  79. $name = $row['column_name'];
  80. $field = [];
  81. $field['type'] = $type = $row['udt_name'];
  82. if (in_array($type, ['char', 'bpchar', 'varchar'])) {
  83. if ($row['character_maximum_length'] !== null) {
  84. $field['length'] = intval($row['character_maximum_length']);
  85. }
  86. }
  87. if ($type == 'numeric') {
  88. // Other int types may report these values, but they're irrelevant.
  89. // Just ignore them!
  90. if ($row['numeric_precision'] !== null) {
  91. $field['precision'] = intval($row['numeric_precision']);
  92. }
  93. if ($row['numeric_scale'] !== null) {
  94. $field['scale'] = intval($row['numeric_scale']);
  95. }
  96. }
  97. if ($row['is_nullable'] == 'NO') {
  98. $field['not null'] = true;
  99. }
  100. $col_default = $row['column_default'];
  101. if (!is_null($col_default)) {
  102. if ($this->isNumericType($field)) {
  103. $field['default'] = (int) $col_default;
  104. } elseif ($type === 'bool') {
  105. $field['default'] = ($col_default === 'true') ? true : false;
  106. } else {
  107. $match = "/^'(.*)'(::.+)*$/";
  108. if (preg_match($match, $col_default)) {
  109. $field['default'] = preg_replace(
  110. $match,
  111. '\1',
  112. $col_default
  113. );
  114. } else {
  115. $field['default'] = $col_default;
  116. }
  117. }
  118. }
  119. if (
  120. $row['is_identity'] === 'YES'
  121. && $row['identity_generation'] = 'BY DEFAULT'
  122. ) {
  123. $field['auto_increment'] = true;
  124. } elseif (array_key_exists($name, $enum_info)) {
  125. $field['enum'] = $enum_info[$name];
  126. }
  127. if (!empty($row['collation_name'])) {
  128. $field['collate'] = $row['collation_name'];
  129. }
  130. $def['fields'][$name] = $field;
  131. }
  132. $key_info = $this->fetchKeyInfo($table);
  133. foreach ($key_info as $row) {
  134. $key_name = $row['key_name'];
  135. $cols = $row['cols'];
  136. switch ($row['key_type']) {
  137. case 'primary':
  138. $def['primary key'] = $cols;
  139. break;
  140. case 'unique':
  141. $def['unique keys'][$key_name] = $cols;
  142. break;
  143. case 'gin':
  144. // @fixme Way too magical.
  145. $cols = array_values(preg_grep(
  146. '/^(.+(\(|\)).+|\s*)$/',
  147. preg_split('(COALESCE\(|,)', $cols[0]),
  148. PREG_GREP_INVERT
  149. ));
  150. $def['fulltext indexes'][$key_name] = $cols;
  151. break;
  152. default:
  153. $def['indexes'][$key_name] = $cols;
  154. }
  155. }
  156. $foreign_key_info = $this->fetchForeignKeyInfo($table);
  157. foreach ($foreign_key_info as $row) {
  158. $key_name = $row['key_name'];
  159. $cols = $row['cols'];
  160. $ref_table = $row['ref_table'];
  161. $def['foreign keys'][$key_name] = [$ref_table, $cols];
  162. }
  163. return $def;
  164. }
  165. /**
  166. * Pull some INFORMATION.SCHEMA data for the given table.
  167. *
  168. * @param string $table
  169. * @param $infoTable
  170. * @param null $orderBy
  171. * @return array of arrays
  172. * @throws PEAR_Exception
  173. */
  174. public function fetchMetaInfo($table, $infoTable, $orderBy = null)
  175. {
  176. $catalog = $this->conn->getDatabase();
  177. $info = $this->fetchQueryData(sprintf(
  178. <<<'END'
  179. SELECT * FROM information_schema.%1$s
  180. WHERE table_catalog = '%2$s' AND table_name = '%3$s'%4$s;
  181. END,
  182. $this->quoteIdentifier($infoTable),
  183. $catalog,
  184. $table,
  185. ($orderBy ? " ORDER BY {$orderBy}" : '')
  186. ));
  187. return array_map(function (array $cols): array {
  188. return array_change_key_case($cols, CASE_LOWER);
  189. }, $info);
  190. }
  191. /**
  192. * Pull index and keys information for the given table.
  193. *
  194. * @param string $table
  195. * @return array of arrays
  196. * @throws PEAR_Exception
  197. */
  198. private function fetchKeyInfo(string $table): array
  199. {
  200. $data = $this->fetchQueryData(sprintf(
  201. <<<'EOT'
  202. SELECT "rel"."relname" AS "key_name",
  203. CASE
  204. WHEN "idx"."indisprimary" IS TRUE THEN 'primary'
  205. WHEN "idx"."indisunique" IS TRUE THEN 'unique'
  206. ELSE "am"."amname"
  207. END AS "key_type",
  208. CASE
  209. WHEN "cols"."attname" IS NOT NULL THEN "cols"."attname"
  210. ELSE pg_get_indexdef("idx"."indexrelid",
  211. CAST("col_nums"."pos" AS INTEGER),
  212. TRUE)
  213. END AS "col"
  214. FROM pg_index AS "idx"
  215. CROSS JOIN LATERAL unnest("idx"."indkey")
  216. WITH ORDINALITY AS "col_nums" ("num", "pos")
  217. INNER JOIN pg_class AS "rel"
  218. ON "idx"."indexrelid" = "rel".oid
  219. LEFT JOIN pg_attribute AS "cols"
  220. ON "idx"."indrelid" = "cols"."attrelid"
  221. AND "col_nums"."num" = "cols"."attnum"
  222. LEFT JOIN pg_am AS "am"
  223. ON "rel"."relam" = "am".oid
  224. WHERE "idx"."indrelid" = CAST('%s' AS REGCLASS)
  225. ORDER BY "key_type", "key_name", "col_nums"."pos";
  226. EOT,
  227. $table
  228. ));
  229. $rows = [];
  230. foreach ($data as $row) {
  231. $name = $row['key_name'];
  232. if (!array_key_exists($name, $rows)) {
  233. $row['cols'] = [$row['col']];
  234. unset($row['col']);
  235. $rows[$name] = $row;
  236. } else {
  237. $rows[$name]['cols'][] = $row['col'];
  238. }
  239. }
  240. return array_values($rows);
  241. }
  242. /**
  243. * Pull foreign key information for the given table.
  244. *
  245. * @param string $table
  246. * @return array array of arrays
  247. * @throws PEAR_Exception
  248. */
  249. private function fetchForeignKeyInfo(string $table): array
  250. {
  251. $data = $this->fetchQueryData(sprintf(
  252. <<<'END'
  253. SELECT "con"."conname" AS "key_name",
  254. "cols"."attname" AS "col",
  255. "ref_rel"."relname" AS "ref_table",
  256. "ref_cols"."attname" AS "ref_col"
  257. FROM pg_constraint AS "con"
  258. CROSS JOIN LATERAL unnest("con"."conkey", "con"."confkey")
  259. WITH ORDINALITY AS "col_nums" ("num", "ref_num", "pos")
  260. LEFT JOIN pg_attribute AS "cols"
  261. ON "con"."conrelid" = "cols"."attrelid"
  262. AND "col_nums"."num" = "cols"."attnum"
  263. LEFT JOIN pg_class AS "ref_rel"
  264. ON "con"."confrelid" = "ref_rel".oid
  265. LEFT JOIN pg_attribute AS "ref_cols"
  266. ON "con"."confrelid" = "ref_cols"."attrelid"
  267. AND "col_nums"."ref_num" = "ref_cols"."attnum"
  268. WHERE "con"."contype" = 'f'
  269. AND "con"."conrelid" = CAST('%s' AS REGCLASS)
  270. ORDER BY "key_name", "col_nums"."pos";
  271. END,
  272. $table
  273. ));
  274. $rows = [];
  275. foreach ($data as $row) {
  276. $name = $row['key_name'];
  277. if (!array_key_exists($name, $rows)) {
  278. $row['cols'] = [$row['col'] => $row['ref_col']];
  279. unset($row['col']);
  280. unset($row['ref_col']);
  281. $rows[$name] = $row;
  282. } else {
  283. $rows[$name]['cols'][$row['col']] = $row['ref_col'];
  284. }
  285. }
  286. return array_values($rows);
  287. }
  288. /**
  289. * Pull information about the emulated enum columns
  290. *
  291. * @param string $table
  292. * @return array of arrays
  293. * @throws PEAR_Exception
  294. */
  295. private function fetchEnumInfo($table)
  296. {
  297. $data = $this->fetchQueryData(
  298. <<<END
  299. SELECT "cols"."attname" AS "col", "con"."consrc" AS "check"
  300. FROM pg_constraint AS "con"
  301. INNER JOIN pg_attribute AS "cols"
  302. ON "con"."conrelid" = "cols"."attrelid"
  303. AND "con"."conkey"[1] = "cols"."attnum"
  304. WHERE "cols".atttypid = CAST('text' AS REGTYPE)
  305. AND "con"."contype" = 'c'
  306. AND cardinality("con"."conkey") = 1
  307. AND "con"."conrelid" = CAST('{$table}' AS REGCLASS);
  308. END
  309. );
  310. $rows = [];
  311. foreach ($data as $row) {
  312. // PostgreSQL can show either
  313. $name_regex = '(' . preg_quote($this->quoteIdentifier($row['col']))
  314. . '|' . preg_quote($row['col']) . ')';
  315. $enum = explode("'::text, '", preg_replace(
  316. "/^\({$name_regex} = ANY \(ARRAY\['(.+)'::text]\)\)$/D",
  317. '\2',
  318. $row['check']
  319. ));
  320. $rows[$row['col']] = $enum;
  321. }
  322. return $rows;
  323. }
  324. private function isNumericType(array $cd): bool
  325. {
  326. $ints = ['int', 'numeric', 'serial'];
  327. return in_array(strtolower($cd['type']), $ints);
  328. }
  329. /**
  330. * Return the proper SQL for creating or
  331. * altering a column.
  332. *
  333. * Appropriate for use in CREATE TABLE or
  334. * ALTER TABLE statements.
  335. *
  336. * @param string $name column name to create
  337. * @param array $cd column to create
  338. *
  339. * @return string correct SQL for that column
  340. */
  341. public function columnSql(string $name, array $cd)
  342. {
  343. $line = [];
  344. $line[] = parent::columnSql($name, $cd);
  345. // This'll have been added from our transform of 'serial' type
  346. if (!empty($cd['auto_increment'])) {
  347. $line[] = 'GENERATED BY DEFAULT AS IDENTITY';
  348. } elseif (!empty($cd['enum'])) {
  349. foreach ($cd['enum'] as &$val) {
  350. $vals[] = "'" . $val . "'";
  351. }
  352. $line[] = 'CHECK (' . $name . ' IN (' . implode(',', $vals) . '))';
  353. }
  354. return implode(' ', $line);
  355. }
  356. public function appendAlterDropPrimary(array &$phrase, string $tableName)
  357. {
  358. // name hack -- is this reliable?
  359. $phrase[] = 'DROP CONSTRAINT ' . $this->quoteIdentifier($tableName . '_pkey');
  360. }
  361. public function buildFulltextIndexList($table, array $def)
  362. {
  363. foreach ($def as &$val) {
  364. $cols[] = $this->buildFulltextIndexItem($table, $val);
  365. }
  366. return "(to_tsvector('english', " . implode(" || ' ' || ", $cols) . '))';
  367. }
  368. public function buildFulltextIndexItem($table, $def)
  369. {
  370. return sprintf(
  371. "COALESCE(%s.%s, '')",
  372. $this->quoteIdentifier($table),
  373. $def
  374. );
  375. }
  376. public function mapType($column)
  377. {
  378. $map = [
  379. 'integer' => 'int',
  380. 'char' => 'bpchar',
  381. 'datetime' => 'timestamp',
  382. 'enum' => 'text',
  383. 'blob' => 'bytea'
  384. ];
  385. $type = $column['type'];
  386. if (array_key_exists($type, $map)) {
  387. $type = $map[$type];
  388. }
  389. $size = $column['size'] ?? null;
  390. switch ($type) {
  391. case 'int':
  392. if (in_array($size, ['tiny', 'small'])) {
  393. $type = 'int2';
  394. } elseif ($size === 'big') {
  395. $type = 'int8';
  396. } else {
  397. $type = 'int4';
  398. }
  399. break;
  400. case 'float':
  401. $type = ($size !== 'big') ? 'float4' : 'float8';
  402. break;
  403. }
  404. return $type;
  405. }
  406. /**
  407. * Collation in PostgreSQL format from our format
  408. *
  409. * @param string $collate
  410. * @return string
  411. */
  412. protected function collationToPostgreSQL(string $collate): string
  413. {
  414. if (!in_array($collate, [
  415. 'utf8_bin',
  416. 'utf8_general_cs',
  417. 'utf8_general_ci',
  418. ])) {
  419. common_log(
  420. LOG_ERR,
  421. 'Collation not supported: "' . $collate . '"'
  422. );
  423. $collate = 'utf8_bin';
  424. }
  425. // @fixme No case-insensitivity support
  426. if (substr($collate, 0, 13) === 'utf8_general_') {
  427. $collate = 'und-x-icu';
  428. } elseif (substr($collate, 0, 8) === 'utf8_bin') {
  429. $collate = 'C';
  430. }
  431. return $collate;
  432. }
  433. public function typeAndSize(string $name, array $column)
  434. {
  435. $col = parent::typeAndSize($name, $column);
  436. if ($this->isStringType($column)) {
  437. if (!empty($column['collate'])) {
  438. $col .= ' COLLATE "' . $column['collate'] . '"';
  439. }
  440. }
  441. return $col;
  442. }
  443. /**
  444. * Append an SQL statement with an index definition for a full-text search
  445. * index over one or more columns on a table.
  446. *
  447. * @param array $statements
  448. * @param string $table
  449. * @param string $name
  450. * @param array $def
  451. */
  452. public function appendCreateFulltextIndex(array &$statements, $table, $name, array $def)
  453. {
  454. $statements[] = "CREATE INDEX {$name} ON {$table} USING gin "
  455. . $this->buildFulltextIndexList($table, $def);
  456. }
  457. /**
  458. * Filter the given table definition array to match features available
  459. * in this database.
  460. *
  461. * This lets us strip out unsupported things like comments, foreign keys,
  462. * or type variants that we wouldn't get back from getTableDef().
  463. *
  464. * @param string $tableName
  465. * @param array $tableDef
  466. * @return array
  467. */
  468. public function filterDef(string $tableName, array $tableDef)
  469. {
  470. $tableDef = parent::filterDef($tableName, $tableDef);
  471. foreach ($tableDef['fields'] as $name => &$col) {
  472. // No convenient support for field descriptions
  473. unset($col['description']);
  474. if ($col['type'] === 'serial') {
  475. $col['type'] = 'int';
  476. $col['auto_increment'] = true;
  477. }
  478. if (!empty($col['collate'])) {
  479. $col['collate'] = $this->collationToPostgreSQL($col['collate']);
  480. }
  481. $col['type'] = $this->mapType($col);
  482. unset($col['size']);
  483. }
  484. if (!empty($tableDef['primary key'])) {
  485. $tableDef['primary key'] = $this->filterKeyDef($tableDef['primary key']);
  486. }
  487. foreach (['unique keys', 'indexes'] as $type) {
  488. if (!empty($tableDef[$type])) {
  489. foreach ($tableDef[$type] as $k => $def) {
  490. $tableDef[$type][$k] = $this->filterKeyDef($def);
  491. }
  492. }
  493. }
  494. return $tableDef;
  495. }
  496. /**
  497. * Filter the given key/index definition to match features available
  498. * in this database.
  499. *
  500. * @param array $def
  501. * @return array
  502. */
  503. public function filterKeyDef(array $def)
  504. {
  505. // PostgreSQL doesn't like prefix lengths specified on keys...?
  506. foreach ($def as $i => $item) {
  507. if (is_array($item)) {
  508. $def[$i] = $item[0];
  509. }
  510. }
  511. return $def;
  512. }
  513. }