pgsqlschema.php 18 KB

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