mysqlschema.php 19 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620
  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. $table_props = $this->getTableProperties($table, ['TABLE_COLLATION']);
  138. $collate = $row['COLLATION_NAME'];
  139. if (!empty($collate) && $collate !== $table_props['TABLE_COLLATION']) {
  140. $field['collate'] = $collate;
  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->dsn['database'];
  204. return $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. }
  215. /**
  216. * Pull index and keys information for the given table.
  217. *
  218. * @param string $table
  219. * @return array of arrays
  220. * @throws PEAR_Exception
  221. */
  222. private function fetchKeyInfo(string $table): array
  223. {
  224. $schema = $this->conn->dsn['database'];
  225. $data = $this->fetchQueryData(
  226. <<<EOT
  227. SELECT INDEX_NAME AS `key_name`,
  228. CASE
  229. WHEN INDEX_NAME = 'PRIMARY' THEN 'PRIMARY'
  230. WHEN NON_UNIQUE IS NOT TRUE THEN 'UNIQUE'
  231. ELSE INDEX_TYPE
  232. END AS `key_type`,
  233. COLUMN_NAME AS `col`,
  234. SUB_PART AS `col_length`
  235. FROM INFORMATION_SCHEMA.STATISTICS
  236. WHERE TABLE_SCHEMA = '{$schema}' AND TABLE_NAME = '{$table}'
  237. ORDER BY `key_name`, `key_type`, SEQ_IN_INDEX;
  238. EOT
  239. );
  240. $rows = [];
  241. foreach ($data as $row) {
  242. $name = $row['key_name'];
  243. if (!is_null($row['col_length'])) {
  244. $row['col'] = [$row['col'], (int) $row['col_length']];
  245. }
  246. unset($row['col_length']);
  247. if (!array_key_exists($name, $rows)) {
  248. $row['cols'] = [$row['col']];
  249. unset($row['col']);
  250. $rows[$name] = $row;
  251. } else {
  252. $rows[$name]['cols'][] = $row['col'];
  253. }
  254. }
  255. return array_values($rows);
  256. }
  257. /**
  258. * Pull foreign key information for the given table.
  259. *
  260. * @param string $table
  261. * @return array array of arrays
  262. * @throws PEAR_Exception
  263. */
  264. private function fetchForeignKeyInfo(string $table): array
  265. {
  266. $schema = $this->conn->dsn['database'];
  267. $data = $this->fetchQueryData(
  268. <<<END
  269. SELECT CONSTRAINT_NAME AS `key_name`,
  270. COLUMN_NAME AS `col`,
  271. REFERENCED_TABLE_NAME AS `ref_table`,
  272. REFERENCED_COLUMN_NAME AS `ref_col`
  273. FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE
  274. WHERE TABLE_SCHEMA = '{$schema}'
  275. AND TABLE_NAME = '{$table}'
  276. AND REFERENCED_TABLE_SCHEMA = '{$schema}'
  277. ORDER BY `key_name`, ORDINAL_POSITION;
  278. END
  279. );
  280. $rows = [];
  281. foreach ($data as $row) {
  282. $name = $row['key_name'];
  283. if (!array_key_exists($name, $rows)) {
  284. $row['cols'] = [$row['col'] => $row['ref_col']];
  285. unset($row['col']);
  286. unset($row['ref_col']);
  287. $rows[$name] = $row;
  288. } else {
  289. $rows[$name]['cols'][$row['col']] = $row['ref_col'];
  290. }
  291. }
  292. return array_values($rows);
  293. }
  294. /**
  295. * Append an SQL statement with an index definition for a full-text search
  296. * index over one or more columns on a table.
  297. *
  298. * @param array $statements
  299. * @param string $table
  300. * @param string $name
  301. * @param array $def
  302. */
  303. public function appendCreateFulltextIndex(array &$statements, $table, $name, array $def)
  304. {
  305. $statements[] = "CREATE FULLTEXT INDEX $name ON $table " . $this->buildIndexList($def);
  306. }
  307. /**
  308. * Append an SQL statement with an index definition for an advisory
  309. * index over one or more columns on a table.
  310. *
  311. * @param array $statements
  312. * @param string $table
  313. * @param string $name
  314. * @param array $def
  315. */
  316. public function appendCreateIndex(array &$statements, $table, $name, array $def)
  317. {
  318. $statements[] = "ALTER TABLE {$this->quoteIdentifier($table)} "
  319. . "ADD INDEX {$name} {$this->buildIndexList($def)}";
  320. }
  321. /**
  322. * Close out a 'create table' SQL statement.
  323. *
  324. * @param string $name
  325. * @param array $def
  326. * @return string;
  327. *
  328. */
  329. public function endCreateTable($name, array $def)
  330. {
  331. $engine = $this->preferredEngine($def);
  332. return ") ENGINE=$engine CHARACTER SET utf8mb4 COLLATE utf8mb4_bin";
  333. }
  334. public function preferredEngine($def)
  335. {
  336. return 'InnoDB';
  337. }
  338. /**
  339. * Append phrase(s) to an array of partial ALTER TABLE chunks in order
  340. * to alter the given column from its old state to a new one.
  341. *
  342. * @param array $phrase
  343. * @param string $columnName
  344. * @param array $old previous column definition as found in DB
  345. * @param array $cd current column definition
  346. */
  347. public function appendAlterModifyColumn(
  348. array &$phrase,
  349. string $columnName,
  350. array $old,
  351. array $cd
  352. ): void {
  353. $phrase[] = 'MODIFY COLUMN ' . $this->quoteIdentifier($columnName)
  354. . ' ' . $this->columnSql($columnName, $cd);
  355. }
  356. /**
  357. * MySQL doesn't take 'DROP CONSTRAINT', need to treat primary keys as
  358. * if they were indexes here, but can use 'PRIMARY KEY' special name.
  359. *
  360. * @param array $phrase
  361. */
  362. public function appendAlterDropPrimary(array &$phrase, string $tableName)
  363. {
  364. $phrase[] = 'DROP PRIMARY KEY';
  365. }
  366. /**
  367. * MySQL doesn't take 'DROP CONSTRAINT', need to treat unique keys as
  368. * if they were indexes here.
  369. *
  370. * @param array $phrase
  371. * @param string $keyName MySQL
  372. */
  373. public function appendAlterDropUnique(array &$phrase, $keyName)
  374. {
  375. $phrase[] = 'DROP INDEX ' . $keyName;
  376. }
  377. public function appendAlterDropForeign(array &$phrase, $keyName)
  378. {
  379. $phrase[] = 'DROP FOREIGN KEY ' . $keyName;
  380. }
  381. /**
  382. * Throw some table metadata onto the ALTER TABLE if we have a mismatch
  383. * in expected type, collation.
  384. * @param array $phrase
  385. * @param $tableName
  386. * @param array $def
  387. * @throws Exception
  388. */
  389. public function appendAlterExtras(array &$phrase, $tableName, array $def)
  390. {
  391. // Check for table properties: make sure we're using a sane
  392. // engine type and collation.
  393. // @fixme make the default engine configurable?
  394. $oldProps = $this->getTableProperties($tableName, ['ENGINE', 'TABLE_COLLATION']);
  395. $engine = $this->preferredEngine($def);
  396. if (strtolower($oldProps['ENGINE']) != strtolower($engine)) {
  397. $phrase[] = "ENGINE=$engine";
  398. }
  399. if (strtolower($oldProps['TABLE_COLLATION']) != 'utf8mb4_bin') {
  400. $phrase[] = 'CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_bin';
  401. $phrase[] = 'DEFAULT CHARACTER SET = utf8mb4';
  402. $phrase[] = 'DEFAULT COLLATE = utf8mb4_bin';
  403. }
  404. }
  405. /**
  406. * Append an SQL statement to drop an index from a table.
  407. * Note that in MariaDB index names are relation-specific.
  408. *
  409. * @param array $statements
  410. * @param string $table
  411. * @param string $name
  412. */
  413. public function appendDropIndex(array &$statements, $table, $name)
  414. {
  415. $statements[] = "ALTER TABLE {$this->quoteIdentifier($table)} "
  416. . "DROP INDEX {$name}";
  417. }
  418. private function isNumericType(array $cd): bool
  419. {
  420. $ints = array_map(
  421. function ($s) {
  422. return $s . 'int';
  423. },
  424. ['tiny', 'small', 'medium', 'big']
  425. );
  426. $ints = array_merge($ints, ['int', 'numeric', 'serial']);
  427. return in_array(strtolower($cd['type']), $ints);
  428. }
  429. /**
  430. * Is this column a string type?
  431. * @param array $cd
  432. * @return bool
  433. */
  434. private function isStringType(array $cd): bool
  435. {
  436. $strings = ['char', 'varchar', 'text'];
  437. return in_array(strtolower($cd['type']), $strings);
  438. }
  439. /**
  440. * Return the proper SQL for creating or
  441. * altering a column.
  442. *
  443. * Appropriate for use in CREATE TABLE or
  444. * ALTER TABLE statements.
  445. *
  446. * @param string $name column name to create
  447. * @param array $cd column to create
  448. *
  449. * @return string correct SQL for that column
  450. */
  451. public function columnSql(string $name, array $cd)
  452. {
  453. $line = [];
  454. $line[] = parent::columnSql($name, $cd);
  455. // This'll have been added from our transform of "serial" type
  456. if (!empty($cd['auto_increment'])) {
  457. $line[] = 'AUTO_INCREMENT';
  458. }
  459. if (!empty($cd['description'])) {
  460. $line[] = 'COMMENT';
  461. $line[] = $this->quoteValue($cd['description']);
  462. }
  463. return implode(' ', $line);
  464. }
  465. public function mapType($column)
  466. {
  467. $map = [
  468. 'integer' => 'int',
  469. 'numeric' => 'decimal',
  470. 'blob' => 'longblob',
  471. ];
  472. $type = $column['type'];
  473. if (array_key_exists($type, $map)) {
  474. $type = $map[$type];
  475. }
  476. $size = $column['size'] ?? null;
  477. switch ($type) {
  478. case 'int':
  479. if (in_array($size, ['tiny', 'small', 'medium', 'big'])) {
  480. $type = $size . $type;
  481. }
  482. break;
  483. case 'float':
  484. if ($size === 'big') {
  485. $type = 'double';
  486. }
  487. break;
  488. case 'text':
  489. if (in_array($size, ['tiny', 'medium', 'long'])) {
  490. $type = $size . $type;
  491. }
  492. break;
  493. }
  494. return $type;
  495. }
  496. public function typeAndSize(string $name, array $column)
  497. {
  498. if ($column['type'] === 'enum') {
  499. $vals = [];
  500. foreach ($column['enum'] as &$val) {
  501. $vals[] = "'{$val}'";
  502. }
  503. return 'enum(' . implode(',', $vals) . ')';
  504. } elseif ($this->isStringType($column)) {
  505. $col = parent::typeAndSize($name, $column);
  506. if (!empty($column['collate'])) {
  507. $col .= ' COLLATE ' . $column['collate'];
  508. }
  509. return $col;
  510. } else {
  511. return parent::typeAndSize($name, $column);
  512. }
  513. }
  514. /**
  515. * Filter the given table definition array to match features available
  516. * in this database.
  517. *
  518. * This lets us strip out unsupported things like comments, foreign keys,
  519. * or type variants that we wouldn't get back from getTableDef().
  520. *
  521. * @param string $tableName
  522. * @param array $tableDef
  523. * @return array
  524. */
  525. public function filterDef(string $tableName, array $tableDef)
  526. {
  527. $tableDef = parent::filterDef($tableName, $tableDef);
  528. // Get existing table collation if the table exists.
  529. // To know if collation that's been set is unique for the table.
  530. try {
  531. $table_props = $this->getTableProperties($tableName, ['TABLE_COLLATION']);
  532. $table_collate = $table_props['TABLE_COLLATION'];
  533. } catch (SchemaTableMissingException $e) {
  534. $table_collate = null;
  535. }
  536. foreach ($tableDef['fields'] as $name => &$col) {
  537. switch ($col['type']) {
  538. case 'serial':
  539. $col['type'] = 'int';
  540. $col['auto_increment'] = true;
  541. break;
  542. case 'bool':
  543. $col['type'] = 'int';
  544. $col['size'] = 'tiny';
  545. $col['default'] = (int) $col['default'];
  546. break;
  547. }
  548. if (!empty($col['collate'])
  549. && $col['collate'] === $table_collate) {
  550. unset($col['collate']);
  551. }
  552. $col['type'] = $this->mapType($col);
  553. unset($col['size']);
  554. }
  555. if (!common_config('db', 'mysql_foreign_keys')) {
  556. unset($tableDef['foreign keys']);
  557. }
  558. return $tableDef;
  559. }
  560. }