mysqlschema.php 19 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579
  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. if (preg_match(
  137. '/(^|\s)on update CURRENT_TIMESTAMP(\(\))?(\s|$)/i',
  138. $extra
  139. )) {
  140. $field['auto_update_timestamp'] = true;
  141. }
  142. }
  143. $table_props = $this->getTableProperties($table, ['TABLE_COLLATION']);
  144. $collate = $row['COLLATION_NAME'];
  145. if (!empty($collate) && $collate !== $table_props['TABLE_COLLATION']) {
  146. $field['collate'] = $collate;
  147. }
  148. $def['fields'][$name] = $field;
  149. }
  150. if ($hasKeys) {
  151. // INFORMATION_SCHEMA's CONSTRAINTS and KEY_COLUMN_USAGE tables give
  152. // good info on primary and unique keys but don't list ANY info on
  153. // multi-value keys, which is lame-o. Sigh.
  154. $keyColumns = $this->fetchMetaInfo($table, 'KEY_COLUMN_USAGE', 'CONSTRAINT_NAME, ORDINAL_POSITION');
  155. $keys = [];
  156. $fkeys = [];
  157. foreach ($keyColumns as $row) {
  158. $keyName = $row['CONSTRAINT_NAME'];
  159. $keyCol = $row['COLUMN_NAME'];
  160. if (!isset($keys[$keyName])) {
  161. $keys[$keyName] = [];
  162. }
  163. $keys[$keyName][] = $keyCol;
  164. if (!is_null($row['REFERENCED_TABLE_NAME'])) {
  165. $fkeys[] = $keyName;
  166. }
  167. }
  168. foreach ($keys as $keyName => $cols) {
  169. if ($keyName === 'PRIMARY') {
  170. $def['primary key'] = $cols;
  171. } elseif (in_array($keyName, $fkeys)) {
  172. $fkey = $this->fetchForeignKeyInfo($table, $keyName);
  173. $colMap = array_combine($cols, $fkey['cols']);
  174. $def['foreign keys'][$keyName] = [$fkey['table_name'], $colMap];
  175. } else {
  176. $def['unique keys'][$keyName] = $cols;
  177. }
  178. }
  179. $indexInfo = $this->fetchIndexInfo($table);
  180. foreach ($indexInfo as $row) {
  181. $keyName = $row['key_name'];
  182. $cols = $row['cols'];
  183. if ($row['key_type'] === 'FULLTEXT') {
  184. $def['fulltext indexes'][$keyName] = $cols;
  185. } else {
  186. $def['indexes'][$keyName] = $cols;
  187. }
  188. }
  189. }
  190. return $def;
  191. }
  192. /**
  193. * Pull the given table properties from INFORMATION_SCHEMA.
  194. * Most of the good stuff is MySQL extensions.
  195. *
  196. * @param $table
  197. * @param $props
  198. * @return array
  199. * @throws PEAR_Exception
  200. * @throws SchemaTableMissingException
  201. */
  202. public function getTableProperties($table, $props)
  203. {
  204. $data = $this->fetchMetaInfo($table, 'TABLES');
  205. if ($data) {
  206. return $data[0];
  207. } else {
  208. throw new SchemaTableMissingException("No such table: $table");
  209. }
  210. }
  211. /**
  212. * Pull some INFORMATION.SCHEMA data for the given table.
  213. *
  214. * @param string $table
  215. * @param $infoTable
  216. * @param null $orderBy
  217. * @return array of arrays
  218. * @throws PEAR_Exception
  219. */
  220. public function fetchMetaInfo($table, $infoTable, $orderBy = null)
  221. {
  222. $query = "SELECT * FROM INFORMATION_SCHEMA.%s " .
  223. "WHERE TABLE_SCHEMA='%s' AND TABLE_NAME='%s'";
  224. $schema = $this->conn->dsn['database'];
  225. $sql = sprintf($query, $infoTable, $schema, $table);
  226. if ($orderBy) {
  227. $sql .= ' ORDER BY ' . $orderBy;
  228. }
  229. return $this->fetchQueryData($sql);
  230. }
  231. /**
  232. * Pull index and keys information for the given table.
  233. *
  234. * @param string $table
  235. * @return array of arrays
  236. * @throws PEAR_Exception
  237. */
  238. public function fetchIndexInfo(string $table): array
  239. {
  240. $query = 'SELECT INDEX_NAME AS `key_name`, INDEX_TYPE AS `key_type`, COLUMN_NAME AS `col` ' .
  241. 'FROM INFORMATION_SCHEMA.STATISTICS ' .
  242. 'WHERE TABLE_SCHEMA = \'%s\' AND TABLE_NAME = \'%s\' AND NON_UNIQUE = TRUE ' .
  243. 'AND INDEX_NAME NOT IN (SELECT CONSTRAINT_NAME FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE WHERE REFERENCED_TABLE_NAME IS NOT NULL) ' .
  244. 'ORDER BY SEQ_IN_INDEX';
  245. $schema = $this->conn->dsn['database'];
  246. $sql = sprintf($query, $schema, $table);
  247. $data = $this->fetchQueryData($sql);
  248. $rows = [];
  249. foreach ($data as $row) {
  250. $name = $row['key_name'];
  251. if (isset($rows[$name])) {
  252. $rows[$name]['cols'][] = $row['col'];
  253. } else {
  254. $row['cols'] = [$row['col']];
  255. unset($row['col']);
  256. $rows[$name] = $row;
  257. }
  258. }
  259. return array_values($rows);
  260. }
  261. /**
  262. * @param string $table
  263. * @param string $constraint_name
  264. * @return array array of rows with keys: table_name, cols (array of strings)
  265. * @throws PEAR_Exception
  266. */
  267. public function fetchForeignKeyInfo(string $table, string $constraint_name): array
  268. {
  269. $query = 'SELECT REFERENCED_TABLE_NAME AS `table_name`, REFERENCED_COLUMN_NAME AS `col` ' .
  270. 'FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE ' .
  271. 'WHERE TABLE_SCHEMA = \'%s\' AND TABLE_NAME = \'%s\' AND CONSTRAINT_NAME = \'%s\' ' .
  272. 'AND REFERENCED_TABLE_SCHEMA IS NOT NULL ' .
  273. 'ORDER BY POSITION_IN_UNIQUE_CONSTRAINT';
  274. $schema = $this->conn->dsn['database'];
  275. $sql = sprintf($query, $schema, $table, $constraint_name);
  276. $data = $this->fetchQueryData($sql);
  277. if (count($data) < 1) {
  278. throw new Exception('Could not find foreign key ' . $constraint_name . ' on table ' . $table);
  279. }
  280. $info = [
  281. 'table_name' => $data[0]['table_name'],
  282. 'cols' => [],
  283. ];
  284. foreach ($data as $row) {
  285. $info['cols'][] = $row['col'];
  286. }
  287. return $info;
  288. }
  289. /**
  290. * Append an SQL statement with an index definition for a full-text search
  291. * index over one or more columns on a table.
  292. *
  293. * @param array $statements
  294. * @param string $table
  295. * @param string $name
  296. * @param array $def
  297. */
  298. public function appendCreateFulltextIndex(array &$statements, $table, $name, array $def)
  299. {
  300. $statements[] = "CREATE FULLTEXT INDEX $name ON $table " . $this->buildIndexList($def);
  301. }
  302. /**
  303. * Close out a 'create table' SQL statement.
  304. *
  305. * @param string $name
  306. * @param array $def
  307. * @return string;
  308. *
  309. */
  310. public function endCreateTable($name, array $def)
  311. {
  312. $engine = $this->preferredEngine($def);
  313. return ") ENGINE=$engine CHARACTER SET utf8mb4 COLLATE utf8mb4_bin";
  314. }
  315. public function preferredEngine($def)
  316. {
  317. /* MyISAM is no longer required for fulltext indexes, fortunately
  318. if (!empty($def['fulltext indexes'])) {
  319. return 'MyISAM';
  320. }
  321. */
  322. return 'InnoDB';
  323. }
  324. /**
  325. * Get the unique index key name for a given column on this table
  326. * @param $tableName
  327. * @param $columnName
  328. * @return string
  329. */
  330. public function _uniqueKey($tableName, $columnName)
  331. {
  332. return $this->_key($tableName, $columnName);
  333. }
  334. /**
  335. * Get the index key name for a given column on this table
  336. * @param $tableName
  337. * @param $columnName
  338. * @return string
  339. */
  340. public function _key($tableName, $columnName)
  341. {
  342. return "{$tableName}_{$columnName}_idx";
  343. }
  344. /**
  345. * MySQL doesn't take 'DROP CONSTRAINT', need to treat primary keys as
  346. * if they were indexes here, but can use 'PRIMARY KEY' special name.
  347. *
  348. * @param array $phrase
  349. */
  350. public function appendAlterDropPrimary(array &$phrase, string $tableName)
  351. {
  352. $phrase[] = 'DROP PRIMARY KEY';
  353. }
  354. /**
  355. * MySQL doesn't take 'DROP CONSTRAINT', need to treat unique keys as
  356. * if they were indexes here.
  357. *
  358. * @param array $phrase
  359. * @param string $keyName MySQL
  360. */
  361. public function appendAlterDropUnique(array &$phrase, $keyName)
  362. {
  363. $phrase[] = 'DROP INDEX ' . $keyName;
  364. }
  365. /**
  366. * Throw some table metadata onto the ALTER TABLE if we have a mismatch
  367. * in expected type, collation.
  368. * @param array $phrase
  369. * @param $tableName
  370. * @param array $def
  371. * @throws Exception
  372. */
  373. public function appendAlterExtras(array &$phrase, $tableName, array $def)
  374. {
  375. // Check for table properties: make sure we're using a sane
  376. // engine type and collation.
  377. // @fixme make the default engine configurable?
  378. $oldProps = $this->getTableProperties($tableName, ['ENGINE', 'TABLE_COLLATION']);
  379. $engine = $this->preferredEngine($def);
  380. if (strtolower($oldProps['ENGINE']) != strtolower($engine)) {
  381. $phrase[] = "ENGINE=$engine";
  382. }
  383. if (strtolower($oldProps['TABLE_COLLATION']) != 'utf8mb4_bin') {
  384. $phrase[] = 'CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_bin';
  385. $phrase[] = 'DEFAULT CHARACTER SET = utf8mb4';
  386. $phrase[] = 'DEFAULT COLLATE = utf8mb4_bin';
  387. }
  388. }
  389. private function isNumericType(array $cd): bool
  390. {
  391. $ints = array_map(
  392. function ($s) {
  393. return $s . 'int';
  394. },
  395. ['tiny', 'small', 'medium', 'big']
  396. );
  397. $ints = array_merge($ints, ['int', 'numeric', 'serial']);
  398. return in_array(strtolower($cd['type']), $ints);
  399. }
  400. /**
  401. * Is this column a string type?
  402. * @param array $cd
  403. * @return bool
  404. */
  405. private function isStringType(array $cd): bool
  406. {
  407. $strings = ['char', 'varchar', 'text'];
  408. return in_array(strtolower($cd['type']), $strings);
  409. }
  410. /**
  411. * Return the proper SQL for creating or
  412. * altering a column.
  413. *
  414. * Appropriate for use in CREATE TABLE or
  415. * ALTER TABLE statements.
  416. *
  417. * @param string $name column name to create
  418. * @param array $cd column to create
  419. *
  420. * @return string correct SQL for that column
  421. */
  422. public function columnSql(string $name, array $cd)
  423. {
  424. $line = [];
  425. $line[] = parent::columnSql($name, $cd);
  426. // This'll have been added from our transform of "serial" type
  427. if (!empty($cd['auto_increment'])) {
  428. $line[] = 'AUTO_INCREMENT';
  429. }
  430. // This'll have been added from our transform of "timestamp" type
  431. if (!empty($cd['auto_update_timestamp'])) {
  432. $line[] = 'ON UPDATE CURRENT_TIMESTAMP';
  433. }
  434. if (!empty($cd['description'])) {
  435. $line[] = 'COMMENT';
  436. $line[] = $this->quoteValue($cd['description']);
  437. }
  438. return implode(' ', $line);
  439. }
  440. public function mapType($column)
  441. {
  442. $map = [
  443. 'integer' => 'int',
  444. 'numeric' => 'decimal',
  445. ];
  446. $type = $column['type'];
  447. if (isset($map[$type])) {
  448. $type = $map[$type];
  449. }
  450. if (!empty($column['size'])) {
  451. $size = $column['size'];
  452. if ($type == 'int' &&
  453. in_array($size, ['tiny', 'small', 'medium', 'big'])) {
  454. $type = $size . $type;
  455. } elseif ($type == 'float' && $size == 'big') {
  456. $type = 'double';
  457. } elseif (in_array($type, ['blob', 'text']) &&
  458. in_array($size, ['tiny', 'medium', 'long'])) {
  459. $type = $size . $type;
  460. }
  461. }
  462. return $type;
  463. }
  464. public function typeAndSize(string $name, array $column)
  465. {
  466. if ($column['type'] === 'enum') {
  467. $vals = [];
  468. foreach ($column['enum'] as &$val) {
  469. $vals[] = "'{$val}'";
  470. }
  471. return 'enum(' . implode(',', $vals) . ')';
  472. } elseif ($this->isStringType($column)) {
  473. $col = parent::typeAndSize($name, $column);
  474. if (!empty($column['collate'])) {
  475. $col .= ' COLLATE ' . $column['collate'];
  476. }
  477. return $col;
  478. } else {
  479. return parent::typeAndSize($name, $column);
  480. }
  481. }
  482. /**
  483. * Filter the given table definition array to match features available
  484. * in this database.
  485. *
  486. * This lets us strip out unsupported things like comments, foreign keys,
  487. * or type variants that we wouldn't get back from getTableDef().
  488. *
  489. * @param string $tableName
  490. * @param array $tableDef
  491. * @return array
  492. */
  493. public function filterDef(string $tableName, array $tableDef)
  494. {
  495. $tableDef = parent::filterDef($tableName, $tableDef);
  496. // Get existing table collation if the table exists.
  497. // To know if collation that's been set is unique for the table.
  498. try {
  499. $table_props = $this->getTableProperties($tableName, ['TABLE_COLLATION']);
  500. $table_collate = $table_props['TABLE_COLLATION'];
  501. } catch (SchemaTableMissingException $e) {
  502. $table_collate = null;
  503. }
  504. foreach ($tableDef['fields'] as $name => &$col) {
  505. switch ($col['type']) {
  506. case 'serial':
  507. $col['type'] = 'int';
  508. $col['auto_increment'] = true;
  509. break;
  510. case 'bool':
  511. $col['type'] = 'int';
  512. $col['size'] = 'tiny';
  513. $col['default'] = (int) $col['default'];
  514. break;
  515. }
  516. if (!empty($col['collate'])
  517. && $col['collate'] === $table_collate) {
  518. unset($col['collate']);
  519. }
  520. $col['type'] = $this->mapType($col);
  521. unset($col['size']);
  522. }
  523. if (!common_config('db', 'mysql_foreign_keys')) {
  524. unset($tableDef['foreign keys']);
  525. }
  526. return $tableDef;
  527. }
  528. }