pgsqlschema.php 18 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570
  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->dsn['database'];
  177. return $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. }
  188. /**
  189. * Pull index and keys information for the given table.
  190. *
  191. * @param string $table
  192. * @return array of arrays
  193. * @throws PEAR_Exception
  194. */
  195. private function fetchKeyInfo(string $table): array
  196. {
  197. $data = $this->fetchQueryData(sprintf(
  198. <<<'EOT'
  199. SELECT "rel"."relname" AS "key_name",
  200. CASE
  201. WHEN "idx"."indisprimary" IS TRUE THEN 'primary'
  202. WHEN "idx"."indisunique" IS TRUE THEN 'unique'
  203. ELSE "am"."amname"
  204. END AS "key_type",
  205. CASE
  206. WHEN "cols"."attname" IS NOT NULL THEN "cols"."attname"
  207. ELSE pg_get_indexdef("idx"."indexrelid",
  208. CAST("col_nums"."pos" AS INTEGER),
  209. TRUE)
  210. END AS "col"
  211. FROM pg_index AS "idx"
  212. CROSS JOIN LATERAL unnest("idx"."indkey")
  213. WITH ORDINALITY AS "col_nums" ("num", "pos")
  214. INNER JOIN pg_class AS "rel"
  215. ON "idx"."indexrelid" = "rel".oid
  216. LEFT JOIN pg_attribute AS "cols"
  217. ON "idx"."indrelid" = "cols"."attrelid"
  218. AND "col_nums"."num" = "cols"."attnum"
  219. LEFT JOIN pg_am AS "am"
  220. ON "rel"."relam" = "am".oid
  221. WHERE "idx"."indrelid" = CAST('%s' AS REGCLASS)
  222. ORDER BY "key_type", "key_name", "col_nums"."pos";
  223. EOT,
  224. $table
  225. ));
  226. $rows = [];
  227. foreach ($data as $row) {
  228. $name = $row['key_name'];
  229. if (!array_key_exists($name, $rows)) {
  230. $row['cols'] = [$row['col']];
  231. unset($row['col']);
  232. $rows[$name] = $row;
  233. } else {
  234. $rows[$name]['cols'][] = $row['col'];
  235. }
  236. }
  237. return array_values($rows);
  238. }
  239. /**
  240. * Pull foreign key information for the given table.
  241. *
  242. * @param string $table
  243. * @return array array of arrays
  244. * @throws PEAR_Exception
  245. */
  246. private function fetchForeignKeyInfo(string $table): array
  247. {
  248. $data = $this->fetchQueryData(sprintf(
  249. <<<'END'
  250. SELECT "con"."conname" AS "key_name",
  251. "cols"."attname" AS "col",
  252. "ref_rel"."relname" AS "ref_table",
  253. "ref_cols"."attname" AS "ref_col"
  254. FROM pg_constraint AS "con"
  255. CROSS JOIN LATERAL unnest("con"."conkey", "con"."confkey")
  256. WITH ORDINALITY AS "col_nums" ("num", "ref_num", "pos")
  257. LEFT JOIN pg_attribute AS "cols"
  258. ON "con"."conrelid" = "cols"."attrelid"
  259. AND "col_nums"."num" = "cols"."attnum"
  260. LEFT JOIN pg_class AS "ref_rel"
  261. ON "con"."confrelid" = "ref_rel".oid
  262. LEFT JOIN pg_attribute AS "ref_cols"
  263. ON "con"."confrelid" = "ref_cols"."attrelid"
  264. AND "col_nums"."ref_num" = "ref_cols"."attnum"
  265. WHERE "con"."contype" = 'f'
  266. AND "con"."conrelid" = CAST('%s' AS REGCLASS)
  267. ORDER BY "key_name", "col_nums"."pos";
  268. END,
  269. $table
  270. ));
  271. $rows = [];
  272. foreach ($data as $row) {
  273. $name = $row['key_name'];
  274. if (!array_key_exists($name, $rows)) {
  275. $row['cols'] = [$row['col'] => $row['ref_col']];
  276. unset($row['col']);
  277. unset($row['ref_col']);
  278. $rows[$name] = $row;
  279. } else {
  280. $rows[$name]['cols'][$row['col']] = $row['ref_col'];
  281. }
  282. }
  283. return array_values($rows);
  284. }
  285. /**
  286. * Pull information about the emulated enum columns
  287. *
  288. * @param string $table
  289. * @return array of arrays
  290. * @throws PEAR_Exception
  291. */
  292. private function fetchEnumInfo($table)
  293. {
  294. $data = $this->fetchQueryData(
  295. <<<END
  296. SELECT "cols"."attname" AS "col", "con"."consrc" AS "check"
  297. FROM pg_constraint AS "con"
  298. INNER JOIN pg_attribute AS "cols"
  299. ON "con"."conrelid" = "cols"."attrelid"
  300. AND "con"."conkey"[1] = "cols"."attnum"
  301. WHERE "cols".atttypid = CAST('text' AS REGTYPE)
  302. AND "con"."contype" = 'c'
  303. AND cardinality("con"."conkey") = 1
  304. AND "con"."conrelid" = CAST('{$table}' AS REGCLASS);
  305. END
  306. );
  307. $rows = [];
  308. foreach ($data as $row) {
  309. // PostgreSQL can show either
  310. $name_regex = '(' . preg_quote($this->quoteIdentifier($row['col']))
  311. . '|' . preg_quote($row['col']) . ')';
  312. $enum = explode("'::text, '", preg_replace(
  313. "/^\({$name_regex} = ANY \(ARRAY\['(.+)'::text]\)\)$/D",
  314. '\2',
  315. $row['check']
  316. ));
  317. $rows[$row['col']] = $enum;
  318. }
  319. return $rows;
  320. }
  321. private function isNumericType(array $cd): bool
  322. {
  323. $ints = ['int', 'numeric', 'serial'];
  324. return in_array(strtolower($cd['type']), $ints);
  325. }
  326. /**
  327. * Return the proper SQL for creating or
  328. * altering a column.
  329. *
  330. * Appropriate for use in CREATE TABLE or
  331. * ALTER TABLE statements.
  332. *
  333. * @param string $name column name to create
  334. * @param array $cd column to create
  335. *
  336. * @return string correct SQL for that column
  337. */
  338. public function columnSql(string $name, array $cd)
  339. {
  340. $line = [];
  341. $line[] = parent::columnSql($name, $cd);
  342. // This'll have been added from our transform of 'serial' type
  343. if (!empty($cd['auto_increment'])) {
  344. $line[] = 'GENERATED BY DEFAULT AS IDENTITY';
  345. } elseif (!empty($cd['enum'])) {
  346. foreach ($cd['enum'] as &$val) {
  347. $vals[] = "'" . $val . "'";
  348. }
  349. $line[] = 'CHECK (' . $name . ' IN (' . implode(',', $vals) . '))';
  350. }
  351. return implode(' ', $line);
  352. }
  353. public function appendAlterDropPrimary(array &$phrase, string $tableName)
  354. {
  355. // name hack -- is this reliable?
  356. $phrase[] = 'DROP CONSTRAINT ' . $this->quoteIdentifier($tableName . '_pkey');
  357. }
  358. public function buildFulltextIndexList($table, array $def)
  359. {
  360. foreach ($def as &$val) {
  361. $cols[] = $this->buildFulltextIndexItem($table, $val);
  362. }
  363. return "(to_tsvector('english', " . implode(" || ' ' || ", $cols) . '))';
  364. }
  365. public function buildFulltextIndexItem($table, $def)
  366. {
  367. return sprintf(
  368. "COALESCE(%s.%s, '')",
  369. $this->quoteIdentifier($table),
  370. $def
  371. );
  372. }
  373. public function mapType($column)
  374. {
  375. $map = [
  376. 'integer' => 'int',
  377. 'char' => 'bpchar',
  378. 'datetime' => 'timestamp',
  379. 'enum' => 'text',
  380. 'blob' => 'bytea'
  381. ];
  382. $type = $column['type'];
  383. if (array_key_exists($type, $map)) {
  384. $type = $map[$type];
  385. }
  386. $size = $column['size'] ?? null;
  387. switch ($type) {
  388. case 'int':
  389. if (in_array($size, ['tiny', 'small'])) {
  390. $type = 'int2';
  391. } elseif ($size === 'big') {
  392. $type = 'int8';
  393. } else {
  394. $type = 'int4';
  395. }
  396. break;
  397. case 'float':
  398. $type = ($size !== 'big') ? 'float4' : 'float8';
  399. break;
  400. }
  401. return $type;
  402. }
  403. /**
  404. * Collation in PostgreSQL format from our format
  405. *
  406. * @param string $collate
  407. * @return string
  408. */
  409. protected function collationToPostgreSQL(string $collate): string
  410. {
  411. if (!in_array($collate, [
  412. 'utf8_bin',
  413. 'utf8_general_cs',
  414. 'utf8_general_ci',
  415. ])) {
  416. common_log(
  417. LOG_ERR,
  418. 'Collation not supported: "' . $collate . '"'
  419. );
  420. $collate = 'utf8_bin';
  421. }
  422. // @fixme No case-insensitivity support
  423. if (substr($collate, 0, 13) === 'utf8_general_') {
  424. $collate = 'und-x-icu';
  425. } elseif (substr($collate, 0, 8) === 'utf8_bin') {
  426. $collate = 'C';
  427. }
  428. return $collate;
  429. }
  430. public function typeAndSize(string $name, array $column)
  431. {
  432. $col = parent::typeAndSize($name, $column);
  433. if ($this->isStringType($column)) {
  434. if (!empty($column['collate'])) {
  435. $col .= ' COLLATE "' . $column['collate'] . '"';
  436. }
  437. }
  438. return $col;
  439. }
  440. /**
  441. * Append an SQL statement with an index definition for a full-text search
  442. * index over one or more columns on a table.
  443. *
  444. * @param array $statements
  445. * @param string $table
  446. * @param string $name
  447. * @param array $def
  448. */
  449. public function appendCreateFulltextIndex(array &$statements, $table, $name, array $def)
  450. {
  451. $statements[] = "CREATE INDEX {$name} ON {$table} USING gin "
  452. . $this->buildFulltextIndexList($table, $def);
  453. }
  454. /**
  455. * Filter the given table definition array to match features available
  456. * in this database.
  457. *
  458. * This lets us strip out unsupported things like comments, foreign keys,
  459. * or type variants that we wouldn't get back from getTableDef().
  460. *
  461. * @param string $tableName
  462. * @param array $tableDef
  463. * @return array
  464. */
  465. public function filterDef(string $tableName, array $tableDef)
  466. {
  467. $tableDef = parent::filterDef($tableName, $tableDef);
  468. foreach ($tableDef['fields'] as $name => &$col) {
  469. // No convenient support for field descriptions
  470. unset($col['description']);
  471. if ($col['type'] === 'serial') {
  472. $col['type'] = 'int';
  473. $col['auto_increment'] = true;
  474. }
  475. if (!empty($col['collate'])) {
  476. $col['collate'] = $this->collationToPostgreSQL($col['collate']);
  477. }
  478. $col['type'] = $this->mapType($col);
  479. unset($col['size']);
  480. }
  481. if (!empty($tableDef['primary key'])) {
  482. $tableDef['primary key'] = $this->filterKeyDef($tableDef['primary key']);
  483. }
  484. foreach (['unique keys', 'indexes'] as $type) {
  485. if (!empty($tableDef[$type])) {
  486. foreach ($tableDef[$type] as $k => $def) {
  487. $tableDef[$type][$k] = $this->filterKeyDef($def);
  488. }
  489. }
  490. }
  491. return $tableDef;
  492. }
  493. /**
  494. * Filter the given key/index definition to match features available
  495. * in this database.
  496. *
  497. * @param array $def
  498. * @return array
  499. */
  500. public function filterKeyDef(array $def)
  501. {
  502. // PostgreSQL doesn't like prefix lengths specified on keys...?
  503. foreach ($def as $i => $item) {
  504. if (is_array($item)) {
  505. $def[$i] = $item[0];
  506. }
  507. }
  508. return $def;
  509. }
  510. }