mysqlschema.php 20 KB

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