mysqlschema.php 17 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525
  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. // warning -- 'unsigned' attr on numbers isn't given in DATA_TYPE and friends.
  79. // It is stuck in on COLUMN_TYPE though (eg 'bigint(20) unsigned')
  80. $field['type'] = $type = $row['DATA_TYPE'];
  81. if ($type == 'char' || $type == 'varchar') {
  82. if ($row['CHARACTER_MAXIMUM_LENGTH'] !== null) {
  83. $field['length'] = intval($row['CHARACTER_MAXIMUM_LENGTH']);
  84. }
  85. }
  86. if ($type == 'decimal') {
  87. // Other int types may report these values, but they're irrelevant.
  88. // Just ignore them!
  89. if ($row['NUMERIC_PRECISION'] !== null) {
  90. $field['precision'] = intval($row['NUMERIC_PRECISION']);
  91. }
  92. if ($row['NUMERIC_SCALE'] !== null) {
  93. $field['scale'] = intval($row['NUMERIC_SCALE']);
  94. }
  95. }
  96. if ($row['IS_NULLABLE'] == 'NO') {
  97. $field['not null'] = true;
  98. }
  99. if ($row['COLUMN_DEFAULT'] !== null) {
  100. // Hack for timestamp columns
  101. if ($row['COLUMN_DEFAULT'] === 'current_timestamp()') {
  102. // skip timestamp columns as they get a CURRENT_TIMESTAMP default implicitly
  103. if ($type !== 'timestamp') {
  104. $field['default'] = 'CURRENT_TIMESTAMP';
  105. }
  106. } elseif ($this->isNumericType($type)) {
  107. $field['default'] = intval($row['COLUMN_DEFAULT']);
  108. } else {
  109. $field['default'] = $row['COLUMN_DEFAULT'];
  110. }
  111. }
  112. if ($row['COLUMN_KEY'] !== null) {
  113. // We'll need to look up key info...
  114. $hasKeys = true;
  115. }
  116. if ($row['COLUMN_COMMENT'] !== null && $row['COLUMN_COMMENT'] != '') {
  117. $field['description'] = $row['COLUMN_COMMENT'];
  118. }
  119. $extra = $row['EXTRA'];
  120. if ($extra) {
  121. if (preg_match('/(^|\s)auto_increment(\s|$)/i', $extra)) {
  122. $field['auto_increment'] = true;
  123. }
  124. // $row['EXTRA'] may contain 'on update CURRENT_TIMESTAMP'
  125. // ^ ...... how to specify?
  126. }
  127. /* @fixme check against defaults?
  128. if ($row['CHARACTER_SET_NAME'] !== null) {
  129. $def['charset'] = $row['CHARACTER_SET_NAME'];
  130. $def['collate'] = $row['COLLATION_NAME'];
  131. }*/
  132. $def['fields'][$name] = $field;
  133. }
  134. if ($hasKeys) {
  135. // INFORMATION_SCHEMA's CONSTRAINTS and KEY_COLUMN_USAGE tables give
  136. // good info on primary and unique keys but don't list ANY info on
  137. // multi-value keys, which is lame-o. Sigh.
  138. $keyColumns = $this->fetchMetaInfo($table, 'KEY_COLUMN_USAGE', 'CONSTRAINT_NAME, ORDINAL_POSITION');
  139. $keys = [];
  140. $fkeys = [];
  141. foreach ($keyColumns as $row) {
  142. $keyName = $row['CONSTRAINT_NAME'];
  143. $keyCol = $row['COLUMN_NAME'];
  144. if (!isset($keys[$keyName])) {
  145. $keys[$keyName] = [];
  146. }
  147. $keys[$keyName][] = $keyCol;
  148. if (!is_null($row['REFERENCED_TABLE_NAME'])) {
  149. $fkeys[] = $keyName;
  150. }
  151. }
  152. foreach ($keys as $keyName => $cols) {
  153. if ($keyName === 'PRIMARY') {
  154. $def['primary key'] = $cols;
  155. } elseif (in_array($keyName, $fkeys)) {
  156. $fkey = $this->fetchForeignKeyInfo($table, $keyName);
  157. $colMap = array_combine($cols, $fkey['cols']);
  158. $def['foreign keys'][$keyName] = [$fkey['table_name'], $colMap];
  159. } else {
  160. $def['unique keys'][$keyName] = $cols;
  161. }
  162. }
  163. $indexInfo = $this->fetchIndexInfo($table);
  164. foreach ($indexInfo as $row) {
  165. $keyName = $row['key_name'];
  166. $cols = $row['cols'];
  167. if ($row['key_type'] === 'FULLTEXT') {
  168. $def['fulltext indexes'][$keyName] = $cols;
  169. } else {
  170. $def['indexes'][$keyName] = $cols;
  171. }
  172. }
  173. }
  174. return $def;
  175. }
  176. /**
  177. * Pull the given table properties from INFORMATION_SCHEMA.
  178. * Most of the good stuff is MySQL extensions.
  179. *
  180. * @param $table
  181. * @param $props
  182. * @return array
  183. * @throws PEAR_Exception
  184. * @throws SchemaTableMissingException
  185. */
  186. public function getTableProperties($table, $props)
  187. {
  188. $data = $this->fetchMetaInfo($table, 'TABLES');
  189. if ($data) {
  190. return $data[0];
  191. } else {
  192. throw new SchemaTableMissingException("No such table: $table");
  193. }
  194. }
  195. /**
  196. * Pull some INFORMATION.SCHEMA data for the given table.
  197. *
  198. * @param string $table
  199. * @param $infoTable
  200. * @param null $orderBy
  201. * @return array of arrays
  202. * @throws PEAR_Exception
  203. */
  204. public function fetchMetaInfo($table, $infoTable, $orderBy = null)
  205. {
  206. $query = "SELECT * FROM INFORMATION_SCHEMA.%s " .
  207. "WHERE TABLE_SCHEMA='%s' AND TABLE_NAME='%s'";
  208. $schema = $this->conn->dsn['database'];
  209. $sql = sprintf($query, $infoTable, $schema, $table);
  210. if ($orderBy) {
  211. $sql .= ' ORDER BY ' . $orderBy;
  212. }
  213. return $this->fetchQueryData($sql);
  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. public function fetchIndexInfo(string $table): array
  223. {
  224. $query = 'SELECT INDEX_NAME AS `key_name`, INDEX_TYPE AS `key_type`, COLUMN_NAME AS `col` ' .
  225. 'FROM INFORMATION_SCHEMA.STATISTICS ' .
  226. 'WHERE TABLE_SCHEMA = \'%s\' AND TABLE_NAME = \'%s\' AND NON_UNIQUE = TRUE ' .
  227. 'AND INDEX_NAME NOT IN (SELECT CONSTRAINT_NAME FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE WHERE REFERENCED_TABLE_NAME IS NOT NULL) ' .
  228. 'ORDER BY SEQ_IN_INDEX';
  229. $schema = $this->conn->dsn['database'];
  230. $sql = sprintf($query, $schema, $table);
  231. $data = $this->fetchQueryData($sql);
  232. $rows = [];
  233. foreach ($data as $row) {
  234. $name = $row['key_name'];
  235. if (isset($rows[$name])) {
  236. $rows[$name]['cols'][] = $row['col'];
  237. } else {
  238. $row['cols'] = [$row['col']];
  239. unset($row['col']);
  240. $rows[$name] = $row;
  241. }
  242. }
  243. return array_values($rows);
  244. }
  245. /**
  246. * @param string $table
  247. * @param string $constraint_name
  248. * @return array array of rows with keys: table_name, cols (array of strings)
  249. * @throws PEAR_Exception
  250. */
  251. public function fetchForeignKeyInfo(string $table, string $constraint_name): array
  252. {
  253. $query = 'SELECT REFERENCED_TABLE_NAME AS `table_name`, REFERENCED_COLUMN_NAME AS `col` ' .
  254. 'FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE ' .
  255. 'WHERE TABLE_SCHEMA = \'%s\' AND TABLE_NAME = \'%s\' AND CONSTRAINT_NAME = \'%s\' ' .
  256. 'AND REFERENCED_TABLE_SCHEMA IS NOT NULL ' .
  257. 'ORDER BY POSITION_IN_UNIQUE_CONSTRAINT';
  258. $schema = $this->conn->dsn['database'];
  259. $sql = sprintf($query, $schema, $table, $constraint_name);
  260. $data = $this->fetchQueryData($sql);
  261. if (count($data) < 1) {
  262. throw new Exception('Could not find foreign key ' . $constraint_name . ' on table ' . $table);
  263. }
  264. $info = [
  265. 'table_name' => $data[0]['table_name'],
  266. 'cols' => [],
  267. ];
  268. foreach ($data as $row) {
  269. $info['cols'][] = $row['col'];
  270. }
  271. return $info;
  272. }
  273. /**
  274. * Append an SQL statement with an index definition for a full-text search
  275. * index over one or more columns on a table.
  276. *
  277. * @param array $statements
  278. * @param string $table
  279. * @param string $name
  280. * @param array $def
  281. */
  282. public function appendCreateFulltextIndex(array &$statements, $table, $name, array $def)
  283. {
  284. $statements[] = "CREATE FULLTEXT INDEX $name ON $table " . $this->buildIndexList($def);
  285. }
  286. /**
  287. * Close out a 'create table' SQL statement.
  288. *
  289. * @param string $name
  290. * @param array $def
  291. * @return string;
  292. *
  293. */
  294. public function endCreateTable($name, array $def)
  295. {
  296. $engine = $this->preferredEngine($def);
  297. return ") ENGINE=$engine CHARACTER SET utf8mb4 COLLATE utf8mb4_bin";
  298. }
  299. public function preferredEngine($def)
  300. {
  301. /* MyISAM is no longer required for fulltext indexes, fortunately
  302. if (!empty($def['fulltext indexes'])) {
  303. return 'MyISAM';
  304. }
  305. */
  306. return 'InnoDB';
  307. }
  308. /**
  309. * Get the unique index key name for a given column on this table
  310. * @param $tableName
  311. * @param $columnName
  312. * @return string
  313. */
  314. public function _uniqueKey($tableName, $columnName)
  315. {
  316. return $this->_key($tableName, $columnName);
  317. }
  318. /**
  319. * Get the index key name for a given column on this table
  320. * @param $tableName
  321. * @param $columnName
  322. * @return string
  323. */
  324. public function _key($tableName, $columnName)
  325. {
  326. return "{$tableName}_{$columnName}_idx";
  327. }
  328. /**
  329. * MySQL doesn't take 'DROP CONSTRAINT', need to treat primary keys as
  330. * if they were indexes here, but can use 'PRIMARY KEY' special name.
  331. *
  332. * @param array $phrase
  333. */
  334. public function appendAlterDropPrimary(array &$phrase, string $tableName)
  335. {
  336. $phrase[] = 'DROP PRIMARY KEY';
  337. }
  338. /**
  339. * MySQL doesn't take 'DROP CONSTRAINT', need to treat unique keys as
  340. * if they were indexes here.
  341. *
  342. * @param array $phrase
  343. * @param string $keyName MySQL
  344. */
  345. public function appendAlterDropUnique(array &$phrase, $keyName)
  346. {
  347. $phrase[] = 'DROP INDEX ' . $keyName;
  348. }
  349. /**
  350. * Throw some table metadata onto the ALTER TABLE if we have a mismatch
  351. * in expected type, collation.
  352. * @param array $phrase
  353. * @param $tableName
  354. * @param array $def
  355. * @throws Exception
  356. */
  357. public function appendAlterExtras(array &$phrase, $tableName, array $def)
  358. {
  359. // Check for table properties: make sure we're using a sane
  360. // engine type and charset/collation.
  361. // @fixme make the default engine configurable?
  362. $oldProps = $this->getTableProperties($tableName, ['ENGINE', 'TABLE_COLLATION']);
  363. $engine = $this->preferredEngine($def);
  364. if (strtolower($oldProps['ENGINE']) != strtolower($engine)) {
  365. $phrase[] = "ENGINE=$engine";
  366. }
  367. if (strtolower($oldProps['TABLE_COLLATION']) != 'utf8mb4_bin') {
  368. $phrase[] = 'CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_bin';
  369. $phrase[] = 'DEFAULT CHARACTER SET = utf8mb4';
  370. $phrase[] = 'DEFAULT COLLATE = utf8mb4_bin';
  371. }
  372. }
  373. /**
  374. * Is this column a string type?
  375. * @param array $cd
  376. * @return bool
  377. */
  378. private function _isString(array $cd)
  379. {
  380. $strings = ['char', 'varchar', 'text'];
  381. return in_array(strtolower($cd['type']), $strings);
  382. }
  383. /**
  384. * Return the proper SQL for creating or
  385. * altering a column.
  386. *
  387. * Appropriate for use in CREATE TABLE or
  388. * ALTER TABLE statements.
  389. *
  390. * @param string $name column name to create
  391. * @param array $cd column to create
  392. *
  393. * @return string correct SQL for that column
  394. */
  395. public function columnSql(string $name, array $cd)
  396. {
  397. $line = [];
  398. $line[] = parent::columnSql($name, $cd);
  399. // This'll have been added from our transform of 'serial' type
  400. if (!empty($cd['auto_increment'])) {
  401. $line[] = 'auto_increment';
  402. }
  403. if (!empty($cd['description'])) {
  404. $line[] = 'comment';
  405. $line[] = $this->quoteValue($cd['description']);
  406. }
  407. return implode(' ', $line);
  408. }
  409. public function mapType($column)
  410. {
  411. $map = [
  412. 'integer' => 'int',
  413. 'bool' => 'tinyint',
  414. 'numeric' => 'decimal',
  415. ];
  416. $type = $column['type'];
  417. if (isset($map[$type])) {
  418. $type = $map[$type];
  419. }
  420. if (!empty($column['size'])) {
  421. $size = $column['size'];
  422. if ($type == 'int' &&
  423. in_array($size, ['tiny', 'small', 'medium', 'big'])) {
  424. $type = $size . $type;
  425. } elseif ($type == 'float' && $size == 'big') {
  426. $type = 'double';
  427. } elseif (in_array($type, ['blob', 'text']) &&
  428. in_array($size, ['tiny', 'medium', 'long'])) {
  429. $type = $size . $type;
  430. }
  431. }
  432. return $type;
  433. }
  434. public function typeAndSize(string $name, array $column)
  435. {
  436. if ($column['type'] === 'enum') {
  437. foreach ($column['enum'] as &$val) {
  438. $vals[] = "'" . $val . "'";
  439. }
  440. return 'enum(' . implode(',', $vals) . ')';
  441. } elseif ($this->_isString($column)) {
  442. $col = parent::typeAndSize($name, $column);
  443. if (!empty($column['charset'])) {
  444. $col .= ' CHARSET ' . $column['charset'];
  445. }
  446. if (!empty($column['collate'])) {
  447. $col .= ' COLLATE ' . $column['collate'];
  448. }
  449. return $col;
  450. } else {
  451. return parent::typeAndSize($name, $column);
  452. }
  453. }
  454. /**
  455. * Filter the given table definition array to match features available
  456. * in this database.
  457. *
  458. * This lets us strip out unsupported things like comments, foreign keys,
  459. * or type variants that we wouldn't get back from getTableDef().
  460. *
  461. * @param array $tableDef
  462. * @return array
  463. */
  464. public function filterDef(array $tableDef)
  465. {
  466. $version = $this->conn->getVersion();
  467. foreach ($tableDef['fields'] as $name => &$col) {
  468. if ($col['type'] == 'serial') {
  469. $col['type'] = 'int';
  470. $col['auto_increment'] = true;
  471. }
  472. $col['type'] = $this->mapType($col);
  473. unset($col['size']);
  474. }
  475. if (!common_config('db', 'mysql_foreign_keys')) {
  476. unset($tableDef['foreign keys']);
  477. }
  478. return $tableDef;
  479. }
  480. }