pgsqlschema.php 17 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519
  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['type'] = $type = 'enum';
  126. $field['enum'] = $enum_info[$name];
  127. }
  128. $def['fields'][$name] = $field;
  129. }
  130. $key_info = $this->fetchKeyInfo($table);
  131. foreach ($key_info as $row) {
  132. $key_name = $row['key_name'];
  133. $cols = $row['cols'];
  134. switch ($row['key_type']) {
  135. case 'primary':
  136. $def['primary key'] = $cols;
  137. break;
  138. case 'unique':
  139. $def['unique keys'][$key_name] = $cols;
  140. break;
  141. case 'gin':
  142. // @fixme Way too magical.
  143. $cols = array_values(preg_grep(
  144. '/^(.+(\(|\)).+|\s*)$/',
  145. preg_split('(COALESCE\(|,)', $cols[0]),
  146. PREG_GREP_INVERT
  147. ));
  148. $def['fulltext indexes'][$key_name] = $cols;
  149. break;
  150. default:
  151. $def['indexes'][$key_name] = $cols;
  152. }
  153. }
  154. $foreign_key_info = $this->fetchForeignKeyInfo($table);
  155. foreach ($foreign_key_info as $row) {
  156. $key_name = $row['key_name'];
  157. $cols = $row['cols'];
  158. $ref_table = $row['ref_table'];
  159. $def['foreign keys'][$key_name] = [$ref_table, $cols];
  160. }
  161. return $def;
  162. }
  163. /**
  164. * Pull some INFORMATION.SCHEMA data for the given table.
  165. *
  166. * @param string $table
  167. * @param $infoTable
  168. * @param null $orderBy
  169. * @return array of arrays
  170. * @throws PEAR_Exception
  171. */
  172. public function fetchMetaInfo($table, $infoTable, $orderBy = null)
  173. {
  174. $catalog = $this->conn->dsn['database'];
  175. return $this->fetchQueryData(sprintf(
  176. <<<'END'
  177. SELECT * FROM information_schema.%1$s
  178. WHERE table_catalog = '%2$s' AND table_name = '%3$s'%4$s;
  179. END,
  180. $this->quoteIdentifier($infoTable),
  181. $catalog,
  182. $table,
  183. ($orderBy ? " ORDER BY {$orderBy}" : '')
  184. ));
  185. }
  186. /**
  187. * Pull index and keys information for the given table.
  188. *
  189. * @param string $table
  190. * @return array of arrays
  191. * @throws PEAR_Exception
  192. */
  193. private function fetchKeyInfo(string $table): array
  194. {
  195. $data = $this->fetchQueryData(sprintf(
  196. <<<'EOT'
  197. SELECT "rel"."relname" AS "key_name",
  198. CASE
  199. WHEN "idx"."indisprimary" IS TRUE THEN 'primary'
  200. WHEN "idx"."indisunique" IS TRUE THEN 'unique'
  201. ELSE "am"."amname"
  202. END AS "key_type",
  203. CASE
  204. WHEN "cols"."attname" IS NOT NULL THEN "cols"."attname"
  205. ELSE pg_get_indexdef("idx"."indexrelid",
  206. CAST("col_nums"."pos" AS INTEGER),
  207. TRUE)
  208. END AS "col"
  209. FROM pg_index AS "idx"
  210. CROSS JOIN LATERAL unnest("idx"."indkey")
  211. WITH ORDINALITY AS "col_nums" ("num", "pos")
  212. INNER JOIN pg_class AS "rel"
  213. ON "idx"."indexrelid" = "rel".oid
  214. LEFT JOIN pg_attribute AS "cols"
  215. ON "idx"."indrelid" = "cols"."attrelid"
  216. AND "col_nums"."num" = "cols"."attnum"
  217. LEFT JOIN pg_am AS "am"
  218. ON "rel"."relam" = "am".oid
  219. WHERE "idx"."indrelid" = CAST('%s' AS REGCLASS)
  220. ORDER BY "key_type", "key_name", "col_nums"."pos";
  221. EOT,
  222. $table
  223. ));
  224. $rows = [];
  225. foreach ($data as $row) {
  226. $name = $row['key_name'];
  227. if (!array_key_exists($name, $rows)) {
  228. $row['cols'] = [$row['col']];
  229. unset($row['col']);
  230. $rows[$name] = $row;
  231. } else {
  232. $rows[$name]['cols'][] = $row['col'];
  233. }
  234. }
  235. return array_values($rows);
  236. }
  237. /**
  238. * Pull foreign key information for the given table.
  239. *
  240. * @param string $table
  241. * @return array array of arrays
  242. * @throws PEAR_Exception
  243. */
  244. private function fetchForeignKeyInfo(string $table): array
  245. {
  246. $data = $this->fetchQueryData(sprintf(
  247. <<<'END'
  248. SELECT "con"."conname" AS "key_name",
  249. "cols"."attname" AS "col",
  250. "ref_rel"."relname" AS "ref_table",
  251. "ref_cols"."attname" AS "ref_col"
  252. FROM pg_constraint AS "con"
  253. CROSS JOIN LATERAL unnest("con"."conkey", "con"."confkey")
  254. WITH ORDINALITY AS "col_nums" ("num", "ref_num", "pos")
  255. LEFT JOIN pg_attribute AS "cols"
  256. ON "con"."conrelid" = "cols"."attrelid"
  257. AND "col_nums"."num" = "cols"."attnum"
  258. LEFT JOIN pg_class AS "ref_rel"
  259. ON "con"."confrelid" = "ref_rel".oid
  260. LEFT JOIN pg_attribute AS "ref_cols"
  261. ON "con"."confrelid" = "ref_cols"."attrelid"
  262. AND "col_nums"."ref_num" = "ref_cols"."attnum"
  263. WHERE "con"."contype" = 'f'
  264. AND "con"."conrelid" = CAST('%s' AS REGCLASS)
  265. ORDER BY "key_name", "col_nums"."pos";
  266. END,
  267. $table
  268. ));
  269. $rows = [];
  270. foreach ($data as $row) {
  271. $name = $row['key_name'];
  272. if (!array_key_exists($name, $rows)) {
  273. $row['cols'] = [$row['col'] => $row['ref_col']];
  274. unset($row['col']);
  275. unset($row['ref_col']);
  276. $rows[$name] = $row;
  277. } else {
  278. $rows[$name]['cols'][$row['col']] = $row['ref_col'];
  279. }
  280. }
  281. return array_values($rows);
  282. }
  283. /**
  284. * Pull information about the emulated enum columns
  285. *
  286. * @param string $table
  287. * @return array of arrays
  288. * @throws PEAR_Exception
  289. */
  290. private function fetchEnumInfo($table)
  291. {
  292. $data = $this->fetchQueryData(
  293. <<<END
  294. SELECT "cols"."attname" AS "col", "con"."consrc" AS "check"
  295. FROM pg_constraint AS "con"
  296. INNER JOIN pg_attribute AS "cols"
  297. ON "con"."conrelid" = "cols"."attrelid"
  298. AND "con"."conkey"[1] = "cols"."attnum"
  299. WHERE "cols".atttypid = CAST('text' AS REGTYPE)
  300. AND "con"."contype" = 'c'
  301. AND cardinality("con"."conkey") = 1
  302. AND "con"."conrelid" = CAST('{$table}' AS REGCLASS);
  303. END
  304. );
  305. $rows = [];
  306. foreach ($data as $row) {
  307. // PostgreSQL can show either
  308. $name_regex = '(' . preg_quote($this->quoteIdentifier($row['col']))
  309. . '|' . preg_quote($row['col']) . ')';
  310. $enum = explode("'::text, '", preg_replace(
  311. "/^\({$name_regex} = ANY \(ARRAY\['(.+)'::text]\)\)$/D",
  312. '\2',
  313. $row['check']
  314. ));
  315. $rows[$row['col']] = $enum;
  316. }
  317. return $rows;
  318. }
  319. private function isNumericType(array $cd): bool
  320. {
  321. $ints = ['int', 'numeric', 'serial'];
  322. return in_array(strtolower($cd['type']), $ints);
  323. }
  324. /**
  325. * Return the proper SQL for creating or
  326. * altering a column.
  327. *
  328. * Appropriate for use in CREATE TABLE or
  329. * ALTER TABLE statements.
  330. *
  331. * @param string $name column name to create
  332. * @param array $cd column to create
  333. *
  334. * @return string correct SQL for that column
  335. */
  336. public function columnSql(string $name, array $cd)
  337. {
  338. $line = [];
  339. $line[] = parent::columnSql($name, $cd);
  340. // This'll have been added from our transform of 'serial' type
  341. if (!empty($cd['auto_increment'])) {
  342. $line[] = 'GENERATED BY DEFAULT AS IDENTITY';
  343. } elseif (!empty($cd['enum'])) {
  344. foreach ($cd['enum'] as &$val) {
  345. $vals[] = "'" . $val . "'";
  346. }
  347. $line[] = 'CHECK (' . $name . ' IN (' . implode(',', $vals) . '))';
  348. }
  349. return implode(' ', $line);
  350. }
  351. public function appendAlterDropPrimary(array &$phrase, string $tableName)
  352. {
  353. // name hack -- is this reliable?
  354. $phrase[] = 'DROP CONSTRAINT ' . $this->quoteIdentifier($tableName . '_pkey');
  355. }
  356. public function buildFulltextIndexList($table, array $def)
  357. {
  358. foreach ($def as &$val) {
  359. $cols[] = $this->buildFulltextIndexItem($table, $val);
  360. }
  361. return "(to_tsvector('english', " . implode(" || ' ' || ", $cols) . '))';
  362. }
  363. public function buildFulltextIndexItem($table, $def)
  364. {
  365. return sprintf(
  366. "COALESCE(%s.%s, '')",
  367. $this->quoteIdentifier($table),
  368. $def
  369. );
  370. }
  371. public function mapType($column)
  372. {
  373. $map = [
  374. 'integer' => 'int',
  375. 'char' => 'bpchar',
  376. 'datetime' => 'timestamp',
  377. 'blob' => 'bytea'
  378. ];
  379. $type = $column['type'];
  380. if (array_key_exists($type, $map)) {
  381. $type = $map[$type];
  382. }
  383. $size = $column['size'] ?? null;
  384. switch ($type) {
  385. case 'int':
  386. if (in_array($size, ['tiny', 'small'])) {
  387. $type = 'int2';
  388. } elseif ($size === 'big') {
  389. $type = 'int8';
  390. } else {
  391. $type = 'int4';
  392. }
  393. break;
  394. case 'float':
  395. $type = ($size !== 'big') ? 'float4' : 'float8';
  396. break;
  397. }
  398. return $type;
  399. }
  400. /**
  401. * Append an SQL statement with an index definition for a full-text search
  402. * index over one or more columns on a table.
  403. *
  404. * @param array $statements
  405. * @param string $table
  406. * @param string $name
  407. * @param array $def
  408. */
  409. public function appendCreateFulltextIndex(array &$statements, $table, $name, array $def)
  410. {
  411. $statements[] = "CREATE INDEX {$name} ON {$table} USING gin "
  412. . $this->buildFulltextIndexList($table, $def);
  413. }
  414. /**
  415. * Filter the given table definition array to match features available
  416. * in this database.
  417. *
  418. * This lets us strip out unsupported things like comments, foreign keys,
  419. * or type variants that we wouldn't get back from getTableDef().
  420. *
  421. * @param string $tableName
  422. * @param array $tableDef
  423. * @return array
  424. */
  425. public function filterDef(string $tableName, array $tableDef)
  426. {
  427. $tableDef = parent::filterDef($tableName, $tableDef);
  428. foreach ($tableDef['fields'] as $name => &$col) {
  429. // No convenient support for field descriptions
  430. unset($col['description']);
  431. // @fixme Nor for MariaDB-specific collations
  432. unset($col['collate']);
  433. if ($col['type'] === 'serial') {
  434. $col['type'] = 'int';
  435. $col['auto_increment'] = true;
  436. }
  437. $col['type'] = $this->mapType($col);
  438. unset($col['size']);
  439. }
  440. if (!empty($tableDef['primary key'])) {
  441. $tableDef['primary key'] = $this->filterKeyDef($tableDef['primary key']);
  442. }
  443. if (!empty($tableDef['unique keys'])) {
  444. foreach ($tableDef['unique keys'] as $i => $def) {
  445. $tableDef['unique keys'][$i] = $this->filterKeyDef($def);
  446. }
  447. }
  448. return $tableDef;
  449. }
  450. /**
  451. * Filter the given key/index definition to match features available
  452. * in this database.
  453. *
  454. * @param array $def
  455. * @return array
  456. */
  457. public function filterKeyDef(array $def)
  458. {
  459. // PostgreSQL doesn't like prefix lengths specified on keys...?
  460. foreach ($def as $i => $item) {
  461. if (is_array($item)) {
  462. $def[$i] = $item[0];
  463. }
  464. }
  465. return $def;
  466. }
  467. }