mysqlschema.php 20 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646
  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 MariaDB
  18. *
  19. * @category Database
  20. * @package GNUsocial
  21. * @author Evan Prodromou <evan@status.net>
  22. * @copyright 2019 Free Software Foundation, Inc http://www.fsf.org
  23. * @license https://www.gnu.org/licenses/agpl.html GNU AGPL v3 or later
  24. */
  25. defined('GNUSOCIAL') || die();
  26. /**
  27. * Class representing the database schema for MariaDB
  28. *
  29. * A class representing the database schema. Can be used to
  30. * manipulate the schema -- especially for plugins and upgrade
  31. * utilities.
  32. *
  33. * @copyright 2019 Free Software Foundation, Inc http://www.fsf.org
  34. * @license https://www.gnu.org/licenses/agpl.html GNU AGPL v3 or later
  35. */
  36. class MysqlSchema extends Schema
  37. {
  38. public static $_single = null;
  39. /**
  40. * Main public entry point. Use this to get
  41. * the singleton object.
  42. *
  43. * @param object|null $conn
  44. * @param string|null dummy param
  45. * @return Schema the (single) Schema object
  46. */
  47. public static function get($conn = null, $_ = 'mysql')
  48. {
  49. if (empty(self::$_single)) {
  50. self::$_single = new Schema($conn, 'mysql');
  51. }
  52. return self::$_single;
  53. }
  54. /**
  55. * Returns a TableDef object for the table
  56. * in the schema with the given name.
  57. *
  58. * Throws an exception if the table is not found.
  59. *
  60. * @param string $table Name of the table to get
  61. *
  62. * @return array of tabledef for that table.
  63. * @throws PEAR_Exception
  64. * @throws SchemaTableMissingException
  65. */
  66. public function getTableDef($table)
  67. {
  68. $def = [];
  69. $hasKeys = false;
  70. // Pull column data from INFORMATION_SCHEMA
  71. $columns = $this->fetchMetaInfo($table, 'COLUMNS', 'ORDINAL_POSITION');
  72. if (count($columns) == 0) {
  73. throw new SchemaTableMissingException("No such table: $table");
  74. }
  75. foreach ($columns as $row) {
  76. $name = $row['COLUMN_NAME'];
  77. $field = [];
  78. $type = $field['type'] = $row['DATA_TYPE'];
  79. switch ($type) {
  80. case 'char':
  81. case 'varchar':
  82. if (!is_null($row['CHARACTER_MAXIMUM_LENGTH'])) {
  83. $field['length'] = (int) $row['CHARACTER_MAXIMUM_LENGTH'];
  84. }
  85. break;
  86. case 'decimal':
  87. // Other int types may report these values, but they're irrelevant.
  88. // Just ignore them!
  89. if (!is_null($row['NUMERIC_PRECISION'])) {
  90. $field['precision'] = (int) $row['NUMERIC_PRECISION'];
  91. }
  92. if (!is_null($row['NUMERIC_SCALE'])) {
  93. $field['scale'] = (int) $row['NUMERIC_SCALE'];
  94. }
  95. break;
  96. case 'enum':
  97. $enum = preg_replace("/^enum\('(.+)'\)$/", '\1', $row['COLUMN_TYPE']);
  98. $field['enum'] = explode("','", $enum);
  99. break;
  100. }
  101. if ($row['IS_NULLABLE'] == 'NO') {
  102. $field['not null'] = true;
  103. }
  104. $col_default = $row['COLUMN_DEFAULT'];
  105. if (!is_null($col_default) && $col_default !== 'NULL') {
  106. if ($this->isNumericType($field)) {
  107. $field['default'] = (int) $col_default;
  108. } elseif ($col_default === 'CURRENT_TIMESTAMP'
  109. || $col_default === 'current_timestamp()') {
  110. // A hack for "datetime" fields
  111. // Skip "timestamp" as they get a CURRENT_TIMESTAMP default implicitly
  112. if ($type !== 'timestamp') {
  113. $field['default'] = 'CURRENT_TIMESTAMP';
  114. }
  115. } else {
  116. $match = "/^'(.*)'$/";
  117. if (preg_match($match, $col_default)) {
  118. $field['default'] = preg_replace($match, '\1', $col_default);
  119. } else {
  120. $field['default'] = $col_default;
  121. }
  122. }
  123. }
  124. if ($row['COLUMN_KEY'] !== null) {
  125. // We'll need to look up key info...
  126. $hasKeys = true;
  127. }
  128. if ($row['COLUMN_COMMENT'] !== null && $row['COLUMN_COMMENT'] != '') {
  129. $field['description'] = $row['COLUMN_COMMENT'];
  130. }
  131. $extra = $row['EXTRA'];
  132. if ($extra) {
  133. if (preg_match('/(^|\s)auto_increment(\s|$)/i', $extra)) {
  134. $field['auto_increment'] = true;
  135. }
  136. }
  137. if (!empty($row['COLLATION_NAME'])) {
  138. $field['collate'] = $row['COLLATION_NAME'];
  139. }
  140. $def['fields'][$name] = $field;
  141. }
  142. if ($hasKeys) {
  143. $key_info = $this->fetchKeyInfo($table);
  144. foreach ($key_info as $row) {
  145. $key_name = $row['key_name'];
  146. $cols = $row['cols'];
  147. switch ($row['key_type']) {
  148. case 'PRIMARY':
  149. $def['primary key'] = $cols;
  150. break;
  151. case 'UNIQUE':
  152. $def['unique keys'][$key_name] = $cols;
  153. break;
  154. case 'FULLTEXT':
  155. $def['fulltext indexes'][$key_name] = $cols;
  156. break;
  157. default:
  158. $def['indexes'][$key_name] = $cols;
  159. }
  160. }
  161. }
  162. $foreign_key_info = $this->fetchForeignKeyInfo($table);
  163. foreach ($foreign_key_info as $row) {
  164. $key_name = $row['key_name'];
  165. $cols = $row['cols'];
  166. $ref_table = $row['ref_table'];
  167. $def['foreign keys'][$key_name] = [$ref_table, $cols];
  168. }
  169. return $def;
  170. }
  171. /**
  172. * Pull the given table properties from INFORMATION_SCHEMA.
  173. * Most of the good stuff is MySQL extensions.
  174. *
  175. * @param $table
  176. * @param $props
  177. * @return array
  178. * @throws PEAR_Exception
  179. * @throws SchemaTableMissingException
  180. */
  181. public function getTableProperties($table, $props)
  182. {
  183. $data = $this->fetchMetaInfo($table, 'TABLES');
  184. if ($data) {
  185. return $data[0];
  186. } else {
  187. throw new SchemaTableMissingException("No such table: $table");
  188. }
  189. }
  190. /**
  191. * Pull some INFORMATION.SCHEMA data for the given table.
  192. *
  193. * @param string $table
  194. * @param $infoTable
  195. * @param null $orderBy
  196. * @return array of arrays
  197. * @throws PEAR_Exception
  198. */
  199. public function fetchMetaInfo($table, $infoTable, $orderBy = null)
  200. {
  201. $schema = $this->conn->getDatabase();
  202. $info = $this->fetchQueryData(sprintf(
  203. <<<'END'
  204. SELECT * FROM INFORMATION_SCHEMA.%1$s
  205. WHERE TABLE_SCHEMA = '%2$s' AND TABLE_NAME = '%3$s'%4$s;
  206. END,
  207. $this->quoteIdentifier($infoTable),
  208. $schema,
  209. $table,
  210. ($orderBy ? " ORDER BY {$orderBy}" : '')
  211. ));
  212. return array_map(function (array $cols): array {
  213. return array_change_key_case($cols, CASE_UPPER);
  214. }, $info);
  215. }
  216. /**
  217. * Pull index and keys information for the given table.
  218. *
  219. * @param string $table
  220. * @return array of arrays
  221. * @throws PEAR_Exception
  222. */
  223. private function fetchKeyInfo(string $table): array
  224. {
  225. $schema = $this->conn->getDatabase();
  226. $data = $this->fetchQueryData(
  227. <<<EOT
  228. SELECT INDEX_NAME AS `key_name`,
  229. CASE
  230. WHEN INDEX_NAME = 'PRIMARY' THEN 'PRIMARY'
  231. WHEN NON_UNIQUE IS NOT TRUE THEN 'UNIQUE'
  232. ELSE INDEX_TYPE
  233. END AS `key_type`,
  234. COLUMN_NAME AS `col`,
  235. SUB_PART AS `col_length`
  236. FROM INFORMATION_SCHEMA.STATISTICS
  237. WHERE TABLE_SCHEMA = '{$schema}' AND TABLE_NAME = '{$table}'
  238. ORDER BY `key_name`, `key_type`, SEQ_IN_INDEX;
  239. EOT
  240. );
  241. $rows = [];
  242. foreach ($data as $row) {
  243. $name = $row['key_name'];
  244. if (!is_null($row['col_length'])) {
  245. $row['col'] = [$row['col'], (int) $row['col_length']];
  246. }
  247. unset($row['col_length']);
  248. if (!array_key_exists($name, $rows)) {
  249. $row['cols'] = [$row['col']];
  250. unset($row['col']);
  251. $rows[$name] = $row;
  252. } else {
  253. $rows[$name]['cols'][] = $row['col'];
  254. }
  255. }
  256. return array_values($rows);
  257. }
  258. /**
  259. * Pull foreign key information for the given table.
  260. *
  261. * @param string $table
  262. * @return array array of arrays
  263. * @throws PEAR_Exception
  264. */
  265. private function fetchForeignKeyInfo(string $table): array
  266. {
  267. $schema = $this->conn->getDatabase();
  268. $data = $this->fetchQueryData(
  269. <<<END
  270. SELECT CONSTRAINT_NAME AS `key_name`,
  271. COLUMN_NAME AS `col`,
  272. REFERENCED_TABLE_NAME AS `ref_table`,
  273. REFERENCED_COLUMN_NAME AS `ref_col`
  274. FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE
  275. WHERE TABLE_SCHEMA = '{$schema}'
  276. AND TABLE_NAME = '{$table}'
  277. AND REFERENCED_TABLE_SCHEMA = '{$schema}'
  278. ORDER BY `key_name`, ORDINAL_POSITION;
  279. END
  280. );
  281. $rows = [];
  282. foreach ($data as $row) {
  283. $name = $row['key_name'];
  284. if (!array_key_exists($name, $rows)) {
  285. $row['cols'] = [$row['col'] => $row['ref_col']];
  286. unset($row['col']);
  287. unset($row['ref_col']);
  288. $rows[$name] = $row;
  289. } else {
  290. $rows[$name]['cols'][$row['col']] = $row['ref_col'];
  291. }
  292. }
  293. return array_values($rows);
  294. }
  295. /**
  296. * Append an SQL statement with an index definition for a full-text search
  297. * index over one or more columns on a table.
  298. *
  299. * @param array $statements
  300. * @param string $table
  301. * @param string $name
  302. * @param array $def
  303. */
  304. public function appendCreateFulltextIndex(array &$statements, $table, $name, array $def)
  305. {
  306. $statements[] = "CREATE FULLTEXT INDEX $name ON $table " . $this->buildIndexList($def);
  307. }
  308. /**
  309. * Append an SQL statement with an index definition for an advisory
  310. * index over one or more columns on a table.
  311. *
  312. * @param array $statements
  313. * @param string $table
  314. * @param string $name
  315. * @param array $def
  316. */
  317. public function appendCreateIndex(array &$statements, $table, $name, array $def)
  318. {
  319. $statements[] = "ALTER TABLE {$this->quoteIdentifier($table)} "
  320. . "ADD INDEX {$name} {$this->buildIndexList($def)}";
  321. }
  322. /**
  323. * Close out a 'create table' SQL statement.
  324. *
  325. * @param string $name
  326. * @param array $def
  327. *
  328. * @return string
  329. */
  330. public function endCreateTable($name, array $def)
  331. {
  332. $engine = self::storageEngine($def);
  333. $charset = self::charset();
  334. return ") ENGINE '{$engine}' "
  335. . "DEFAULT CHARACTER SET '{$charset}' "
  336. . "DEFAULT COLLATE '{$charset}_bin'";
  337. }
  338. /**
  339. * Returns the character set of choice for MariaDB.
  340. * Overrides default standard "UTF8".
  341. *
  342. * @return string
  343. */
  344. public static function charset(): string
  345. {
  346. return 'utf8mb4';
  347. }
  348. /**
  349. * Returns the storage engine of choice for the supplied definition.
  350. *
  351. * @param array $def
  352. * @return string
  353. */
  354. protected static function storageEngine(array $def): string
  355. {
  356. return 'InnoDB';
  357. }
  358. /**
  359. * Append phrase(s) to an array of partial ALTER TABLE chunks in order
  360. * to alter the given column from its old state to a new one.
  361. *
  362. * @param array $phrase
  363. * @param string $columnName
  364. * @param array $old previous column definition as found in DB
  365. * @param array $cd current column definition
  366. */
  367. public function appendAlterModifyColumn(
  368. array &$phrase,
  369. string $columnName,
  370. array $old,
  371. array $cd
  372. ): void {
  373. $phrase[] = 'MODIFY COLUMN ' . $this->quoteIdentifier($columnName)
  374. . ' ' . $this->columnSql($columnName, $cd);
  375. }
  376. /**
  377. * MySQL doesn't take 'DROP CONSTRAINT', need to treat primary keys as
  378. * if they were indexes here, but can use 'PRIMARY KEY' special name.
  379. *
  380. * @param array $phrase
  381. */
  382. public function appendAlterDropPrimary(array &$phrase, string $tableName)
  383. {
  384. $phrase[] = 'DROP PRIMARY KEY';
  385. }
  386. /**
  387. * MySQL doesn't take 'DROP CONSTRAINT', need to treat unique keys as
  388. * if they were indexes here.
  389. *
  390. * @param array $phrase
  391. * @param string $keyName MySQL
  392. */
  393. public function appendAlterDropUnique(array &$phrase, $keyName)
  394. {
  395. $phrase[] = 'DROP INDEX ' . $keyName;
  396. }
  397. public function appendAlterDropForeign(array &$phrase, $keyName)
  398. {
  399. $phrase[] = 'DROP FOREIGN KEY ' . $keyName;
  400. }
  401. /**
  402. * Throw some table metadata onto the ALTER TABLE if we have a mismatch
  403. * in expected type, collation.
  404. * @param array $phrase
  405. * @param $tableName
  406. * @param array $def
  407. * @throws Exception
  408. */
  409. public function appendAlterExtras(array &$phrase, $tableName, array $def)
  410. {
  411. // Check for table properties: make sure we are using sane
  412. // storage engine, character set and collation.
  413. $oldProps = $this->getTableProperties($tableName, ['ENGINE', 'TABLE_COLLATION']);
  414. $engine = self::storageEngine($def);
  415. $charset = self::charset();
  416. if (mb_strtolower($oldProps['ENGINE']) !== mb_strtolower($engine)) {
  417. $phrase[] = "ENGINE '{$engine}'";
  418. }
  419. if (strtolower($oldProps['TABLE_COLLATION']) !== "{$charset}_bin") {
  420. $phrase[] = "CONVERT TO CHARACTER SET '{$charset} COLLATE '{$charset}_bin'";
  421. $phrase[] = "DEFAULT CHARACTER SET '{$charset}'";
  422. $phrase[] = "DEFAULT COLLATE '{$charset}_bin'";
  423. }
  424. }
  425. /**
  426. * Append an SQL statement to drop an index from a table.
  427. * Note that in MariaDB index names are relation-specific.
  428. *
  429. * @param array $statements
  430. * @param string $table
  431. * @param string $name
  432. */
  433. public function appendDropIndex(array &$statements, $table, $name)
  434. {
  435. $statements[] = "ALTER TABLE {$this->quoteIdentifier($table)} "
  436. . "DROP INDEX {$name}";
  437. }
  438. private function isNumericType(array $cd): bool
  439. {
  440. $ints = array_map(
  441. function ($s) {
  442. return $s . 'int';
  443. },
  444. ['tiny', 'small', 'medium', 'big']
  445. );
  446. $ints = array_merge($ints, ['int', 'numeric', 'serial']);
  447. return in_array(strtolower($cd['type']), $ints);
  448. }
  449. /**
  450. * Return the proper SQL for creating or
  451. * altering a column.
  452. *
  453. * Appropriate for use in CREATE TABLE or
  454. * ALTER TABLE statements.
  455. *
  456. * @param string $name column name to create
  457. * @param array $cd column to create
  458. *
  459. * @return string correct SQL for that column
  460. */
  461. public function columnSql(string $name, array $cd)
  462. {
  463. $line = [];
  464. $line[] = parent::columnSql($name, $cd);
  465. // This'll have been added from our transform of "serial" type
  466. if (!empty($cd['auto_increment'])) {
  467. $line[] = 'AUTO_INCREMENT';
  468. }
  469. if (!empty($cd['description'])) {
  470. $line[] = 'COMMENT';
  471. $line[] = $this->quoteValue($cd['description']);
  472. }
  473. return implode(' ', $line);
  474. }
  475. public function mapType($column)
  476. {
  477. $map = [
  478. 'integer' => 'int',
  479. 'numeric' => 'decimal',
  480. 'blob' => 'longblob',
  481. ];
  482. $type = $column['type'];
  483. if (array_key_exists($type, $map)) {
  484. $type = $map[$type];
  485. }
  486. $size = $column['size'] ?? null;
  487. switch ($type) {
  488. case 'int':
  489. if (in_array($size, ['tiny', 'small', 'medium', 'big'])) {
  490. $type = $size . $type;
  491. }
  492. break;
  493. case 'float':
  494. if ($size === 'big') {
  495. $type = 'double';
  496. }
  497. break;
  498. case 'text':
  499. if (in_array($size, ['tiny', 'medium', 'long'])) {
  500. $type = $size . $type;
  501. }
  502. break;
  503. }
  504. return $type;
  505. }
  506. /**
  507. * Collation in MariaDB format from our format
  508. *
  509. * @param string $collate
  510. * @return string
  511. */
  512. protected function collationToMySQL(string $collate): string
  513. {
  514. if (!in_array($collate, [
  515. 'utf8_bin',
  516. 'utf8_general_cs',
  517. 'utf8_general_ci',
  518. ])) {
  519. common_log(
  520. LOG_ERR,
  521. 'Collation not supported: "' . $collate . '"'
  522. );
  523. $collate = 'utf8_bin';
  524. }
  525. if (substr($collate, 0, 13) === 'utf8_general_') {
  526. $collate = 'utf8mb4_unicode_' . substr($collate, 13);
  527. } elseif (substr($collate, 0, 5) === 'utf8_') {
  528. $collate = 'utf8mb4_' . substr($collate, 5);
  529. }
  530. return $collate;
  531. }
  532. public function typeAndSize(string $name, array $column)
  533. {
  534. if ($column['type'] === 'enum') {
  535. $vals = [];
  536. foreach ($column['enum'] as &$val) {
  537. $vals[] = "'{$val}'";
  538. }
  539. return 'ENUM(' . implode(',', $vals) . ')';
  540. } elseif ($this->isStringType($column)) {
  541. $col = parent::typeAndSize($name, $column);
  542. if (!empty($column['collate'])) {
  543. $col .= " COLLATE '{$column['collate']}'";
  544. }
  545. return $col;
  546. } else {
  547. return parent::typeAndSize($name, $column);
  548. }
  549. }
  550. /**
  551. * Filter the given table definition array to match features available
  552. * in this database.
  553. *
  554. * This lets us strip out unsupported things like comments, foreign keys,
  555. * or type variants that we wouldn't get back from getTableDef().
  556. *
  557. * @param string $tableName
  558. * @param array $tableDef
  559. * @return array
  560. */
  561. public function filterDef(string $tableName, array $tableDef)
  562. {
  563. $tableDef = parent::filterDef($tableName, $tableDef);
  564. foreach ($tableDef['fields'] as $name => &$col) {
  565. switch ($col['type']) {
  566. case 'serial':
  567. $col['type'] = 'int';
  568. $col['auto_increment'] = true;
  569. break;
  570. case 'bool':
  571. $col['type'] = 'int';
  572. $col['size'] = 'tiny';
  573. $col['default'] = (int) $col['default'];
  574. break;
  575. }
  576. if (!empty($col['collate'])) {
  577. $col['collate'] = $this->collationToMySQL($col['collate']);
  578. }
  579. $col['type'] = $this->mapType($col);
  580. unset($col['size']);
  581. }
  582. return $tableDef;
  583. }
  584. }