mysqlschema.php 15 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475
  1. <?php
  2. /**
  3. * StatusNet, the distributed open-source microblogging tool
  4. *
  5. * Database schema utilities
  6. *
  7. * PHP version 5
  8. *
  9. * LICENCE: This program is free software: you can redistribute it and/or modify
  10. * it under the terms of the GNU Affero General Public License as published by
  11. * the Free Software Foundation, either version 3 of the License, or
  12. * (at your option) any later version.
  13. *
  14. * This program is distributed in the hope that it will be useful,
  15. * but WITHOUT ANY WARRANTY; without even the implied warranty of
  16. * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
  17. * GNU Affero General Public License for more details.
  18. *
  19. * You should have received a copy of the GNU Affero General Public License
  20. * along with this program. If not, see <http://www.gnu.org/licenses/>.
  21. *
  22. * @category Database
  23. * @package StatusNet
  24. * @author Evan Prodromou <evan@status.net>
  25. * @copyright 2009 StatusNet, Inc.
  26. * @license http://www.fsf.org/licensing/licenses/agpl-3.0.html GNU Affero General Public License version 3.0
  27. * @link http://status.net/
  28. */
  29. if (!defined('STATUSNET')) {
  30. exit(1);
  31. }
  32. /**
  33. * Class representing the database schema
  34. *
  35. * A class representing the database schema. Can be used to
  36. * manipulate the schema -- especially for plugins and upgrade
  37. * utilities.
  38. *
  39. * @category Database
  40. * @package StatusNet
  41. * @author Evan Prodromou <evan@status.net>
  42. * @license http://www.fsf.org/licensing/licenses/agpl-3.0.html GNU Affero General Public License version 3.0
  43. * @link http://status.net/
  44. */
  45. class MysqlSchema extends Schema
  46. {
  47. static $_single = null;
  48. protected $conn = null;
  49. /**
  50. * Main public entry point. Use this to get
  51. * the singleton object.
  52. *
  53. * @return Schema the (single) Schema object
  54. */
  55. static function get($conn = null)
  56. {
  57. if (empty(self::$_single)) {
  58. self::$_single = new Schema($conn);
  59. }
  60. return self::$_single;
  61. }
  62. /**
  63. * Returns a TableDef object for the table
  64. * in the schema with the given name.
  65. *
  66. * Throws an exception if the table is not found.
  67. *
  68. * @param string $table Name of the table to get
  69. *
  70. * @return TableDef tabledef for that table.
  71. * @throws SchemaTableMissingException
  72. */
  73. public function getTableDef($table)
  74. {
  75. $def = array();
  76. $hasKeys = false;
  77. // Pull column data from INFORMATION_SCHEMA
  78. $columns = $this->fetchMetaInfo($table, 'COLUMNS', 'ORDINAL_POSITION');
  79. if (count($columns) == 0) {
  80. throw new SchemaTableMissingException("No such table: $table");
  81. }
  82. foreach ($columns as $row) {
  83. $name = $row['COLUMN_NAME'];
  84. $field = array();
  85. // warning -- 'unsigned' attr on numbers isn't given in DATA_TYPE and friends.
  86. // It is stuck in on COLUMN_TYPE though (eg 'bigint(20) unsigned')
  87. $field['type'] = $type = $row['DATA_TYPE'];
  88. if ($type == 'char' || $type == 'varchar') {
  89. if ($row['CHARACTER_MAXIMUM_LENGTH'] !== null) {
  90. $field['length'] = intval($row['CHARACTER_MAXIMUM_LENGTH']);
  91. }
  92. }
  93. if ($type == 'decimal') {
  94. // Other int types may report these values, but they're irrelevant.
  95. // Just ignore them!
  96. if ($row['NUMERIC_PRECISION'] !== null) {
  97. $field['precision'] = intval($row['NUMERIC_PRECISION']);
  98. }
  99. if ($row['NUMERIC_SCALE'] !== null) {
  100. $field['scale'] = intval($row['NUMERIC_SCALE']);
  101. }
  102. }
  103. if ($row['IS_NULLABLE'] == 'NO') {
  104. $field['not null'] = true;
  105. }
  106. if ($row['COLUMN_DEFAULT'] !== null) {
  107. // Hack for timestamp cols
  108. if ($type == 'timestamp' && $row['COLUMN_DEFAULT'] == 'CURRENT_TIMESTAMP') {
  109. // skip
  110. } else {
  111. $field['default'] = $row['COLUMN_DEFAULT'];
  112. if ($this->isNumericType($type)) {
  113. $field['default'] = intval($field['default']);
  114. }
  115. }
  116. }
  117. if ($row['COLUMN_KEY'] !== null) {
  118. // We'll need to look up key info...
  119. $hasKeys = true;
  120. }
  121. if ($row['COLUMN_COMMENT'] !== null && $row['COLUMN_COMMENT'] != '') {
  122. $field['description'] = $row['COLUMN_COMMENT'];
  123. }
  124. $extra = $row['EXTRA'];
  125. if ($extra) {
  126. if (preg_match('/(^|\s)auto_increment(\s|$)/i', $extra)) {
  127. $field['auto_increment'] = true;
  128. }
  129. // $row['EXTRA'] may contain 'on update CURRENT_TIMESTAMP'
  130. // ^ ...... how to specify?
  131. }
  132. if ($row['CHARACTER_SET_NAME'] !== null) {
  133. // @fixme check against defaults?
  134. //$def['charset'] = $row['CHARACTER_SET_NAME'];
  135. //$def['collate'] = $row['COLLATION_NAME'];
  136. }
  137. $def['fields'][$name] = $field;
  138. }
  139. if ($hasKeys) {
  140. // INFORMATION_SCHEMA's CONSTRAINTS and KEY_COLUMN_USAGE tables give
  141. // good info on primary and unique keys but don't list ANY info on
  142. // multi-value keys, which is lame-o. Sigh.
  143. //
  144. // Let's go old school and use SHOW INDEX :D
  145. //
  146. $keyInfo = $this->fetchIndexInfo($table);
  147. $keys = array();
  148. foreach ($keyInfo as $row) {
  149. $name = $row['Key_name'];
  150. $column = $row['Column_name'];
  151. if (!isset($keys[$name])) {
  152. $keys[$name] = array();
  153. }
  154. $keys[$name][] = $column;
  155. if ($name == 'PRIMARY') {
  156. $type = 'primary key';
  157. } else if ($row['Non_unique'] == 0) {
  158. $type = 'unique keys';
  159. } else if ($row['Index_type'] == 'FULLTEXT') {
  160. $type = 'fulltext indexes';
  161. } else {
  162. $type = 'indexes';
  163. }
  164. $keyTypes[$name] = $type;
  165. }
  166. foreach ($keyTypes as $name => $type) {
  167. if ($type == 'primary key') {
  168. // there can be only one
  169. $def[$type] = $keys[$name];
  170. } else {
  171. $def[$type][$name] = $keys[$name];
  172. }
  173. }
  174. }
  175. return $def;
  176. }
  177. /**
  178. * Pull the given table properties from INFORMATION_SCHEMA.
  179. * Most of the good stuff is MySQL extensions.
  180. *
  181. * @return array
  182. * @throws Exception if table info can't be looked up
  183. */
  184. function getTableProperties($table, $props)
  185. {
  186. $data = $this->fetchMetaInfo($table, 'TABLES');
  187. if ($data) {
  188. return $data[0];
  189. } else {
  190. throw new SchemaTableMissingException("No such table: $table");
  191. }
  192. }
  193. /**
  194. * Pull some INFORMATION.SCHEMA data for the given table.
  195. *
  196. * @param string $table
  197. * @return array of arrays
  198. */
  199. function fetchMetaInfo($table, $infoTable, $orderBy=null)
  200. {
  201. $query = "SELECT * FROM INFORMATION_SCHEMA.%s " .
  202. "WHERE TABLE_SCHEMA='%s' AND TABLE_NAME='%s'";
  203. $schema = $this->conn->dsn['database'];
  204. $sql = sprintf($query, $infoTable, $schema, $table);
  205. if ($orderBy) {
  206. $sql .= ' ORDER BY ' . $orderBy;
  207. }
  208. return $this->fetchQueryData($sql);
  209. }
  210. /**
  211. * Pull 'SHOW INDEX' data for the given table.
  212. *
  213. * @param string $table
  214. * @return array of arrays
  215. */
  216. function fetchIndexInfo($table)
  217. {
  218. $query = "SHOW INDEX FROM `%s`";
  219. $sql = sprintf($query, $table);
  220. return $this->fetchQueryData($sql);
  221. }
  222. /**
  223. * Append an SQL statement with an index definition for a full-text search
  224. * index over one or more columns on a table.
  225. *
  226. * @param array $statements
  227. * @param string $table
  228. * @param string $name
  229. * @param array $def
  230. */
  231. function appendCreateFulltextIndex(array &$statements, $table, $name, array $def)
  232. {
  233. $statements[] = "CREATE FULLTEXT INDEX $name ON $table " . $this->buildIndexList($def);
  234. }
  235. /**
  236. * Close out a 'create table' SQL statement.
  237. *
  238. * @param string $name
  239. * @param array $def
  240. * @return string;
  241. *
  242. */
  243. function endCreateTable($name, array $def)
  244. {
  245. $engine = $this->preferredEngine($def);
  246. return ") ENGINE=$engine CHARACTER SET utf8mb4 COLLATE utf8mb4_bin";
  247. }
  248. function preferredEngine($def)
  249. {
  250. /* MyISAM is no longer required for fulltext indexes, fortunately
  251. if (!empty($def['fulltext indexes'])) {
  252. return 'MyISAM';
  253. }
  254. */
  255. return 'InnoDB';
  256. }
  257. /**
  258. * Get the unique index key name for a given column on this table
  259. */
  260. function _uniqueKey($tableName, $columnName)
  261. {
  262. return $this->_key($tableName, $columnName);
  263. }
  264. /**
  265. * Get the index key name for a given column on this table
  266. */
  267. function _key($tableName, $columnName)
  268. {
  269. return "{$tableName}_{$columnName}_idx";
  270. }
  271. /**
  272. * MySQL doesn't take 'DROP CONSTRAINT', need to treat primary keys as
  273. * if they were indexes here, but can use 'PRIMARY KEY' special name.
  274. *
  275. * @param array $phrase
  276. */
  277. function appendAlterDropPrimary(array &$phrase)
  278. {
  279. $phrase[] = 'DROP PRIMARY KEY';
  280. }
  281. /**
  282. * MySQL doesn't take 'DROP CONSTRAINT', need to treat unique keys as
  283. * if they were indexes here.
  284. *
  285. * @param array $phrase
  286. * @param <type> $keyName MySQL
  287. */
  288. function appendAlterDropUnique(array &$phrase, $keyName)
  289. {
  290. $phrase[] = 'DROP INDEX ' . $keyName;
  291. }
  292. /**
  293. * Throw some table metadata onto the ALTER TABLE if we have a mismatch
  294. * in expected type, collation.
  295. */
  296. function appendAlterExtras(array &$phrase, $tableName, array $def)
  297. {
  298. // Check for table properties: make sure we're using a sane
  299. // engine type and charset/collation.
  300. // @fixme make the default engine configurable?
  301. $oldProps = $this->getTableProperties($tableName, array('ENGINE', 'TABLE_COLLATION'));
  302. $engine = $this->preferredEngine($def);
  303. if (strtolower($oldProps['ENGINE']) != strtolower($engine)) {
  304. $phrase[] = "ENGINE=$engine";
  305. }
  306. if (strtolower($oldProps['TABLE_COLLATION']) != 'utf8mb4_bin') {
  307. $phrase[] = 'CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_bin';
  308. $phrase[] = 'DEFAULT CHARACTER SET = utf8mb4';
  309. $phrase[] = 'DEFAULT COLLATE = utf8mb4_bin';
  310. }
  311. }
  312. /**
  313. * Is this column a string type?
  314. */
  315. private function _isString(array $cd)
  316. {
  317. $strings = array('char', 'varchar', 'text');
  318. return in_array(strtolower($cd['type']), $strings);
  319. }
  320. /**
  321. * Return the proper SQL for creating or
  322. * altering a column.
  323. *
  324. * Appropriate for use in CREATE TABLE or
  325. * ALTER TABLE statements.
  326. *
  327. * @param ColumnDef $cd column to create
  328. *
  329. * @return string correct SQL for that column
  330. */
  331. function columnSql(array $cd)
  332. {
  333. $line = array();
  334. $line[] = parent::columnSql($cd);
  335. // This'll have been added from our transform of 'serial' type
  336. if (!empty($cd['auto_increment'])) {
  337. $line[] = 'auto_increment';
  338. }
  339. if (!empty($cd['description'])) {
  340. $line[] = 'comment';
  341. $line[] = $this->quoteValue($cd['description']);
  342. }
  343. return implode(' ', $line);
  344. }
  345. function mapType($column)
  346. {
  347. $map = array('serial' => 'int',
  348. 'integer' => 'int',
  349. 'numeric' => 'decimal');
  350. $type = $column['type'];
  351. if (isset($map[$type])) {
  352. $type = $map[$type];
  353. }
  354. if (!empty($column['size'])) {
  355. $size = $column['size'];
  356. if ($type == 'int' &&
  357. in_array($size, array('tiny', 'small', 'medium', 'big'))) {
  358. $type = $size . $type;
  359. } else if (in_array($type, array('blob', 'text')) &&
  360. in_array($size, array('tiny', 'medium', 'long'))) {
  361. $type = $size . $type;
  362. }
  363. }
  364. return $type;
  365. }
  366. function typeAndSize($column)
  367. {
  368. if ($column['type'] == 'enum') {
  369. $vals = array_map(array($this, 'quote'), $column['enum']);
  370. return 'enum(' . implode(',', $vals) . ')';
  371. } else if ($this->_isString($column)) {
  372. $col = parent::typeAndSize($column);
  373. if (!empty($column['charset'])) {
  374. $col .= ' CHARSET ' . $column['charset'];
  375. }
  376. if (!empty($column['collate'])) {
  377. $col .= ' COLLATE ' . $column['collate'];
  378. }
  379. return $col;
  380. } else {
  381. return parent::typeAndSize($column);
  382. }
  383. }
  384. /**
  385. * Filter the given table definition array to match features available
  386. * in this database.
  387. *
  388. * This lets us strip out unsupported things like comments, foreign keys,
  389. * or type variants that we wouldn't get back from getTableDef().
  390. *
  391. * @param array $tableDef
  392. */
  393. function filterDef(array $tableDef)
  394. {
  395. $version = $this->conn->getVersion();
  396. foreach ($tableDef['fields'] as $name => &$col) {
  397. if ($col['type'] == 'serial') {
  398. $col['type'] = 'int';
  399. $col['auto_increment'] = true;
  400. }
  401. // Avoid invalid date errors in MySQL 5.7+
  402. if ($col['type'] == 'timestamp' && !isset($col['default'])
  403. && $version >= 50605) {
  404. $col['default'] = 'CURRENT_TIMESTAMP';
  405. }
  406. if ($col['type'] == 'datetime') {
  407. // Avoid invalid date errors in MySQL 5.7+
  408. if (!isset($col['default']) && $version >= 50605) {
  409. $col['default'] = 'CURRENT_TIMESTAMP';
  410. }
  411. // If we are using MySQL 5.5, convert datetime to timestamp if
  412. // default value is CURRENT_TIMESTAMP. Not needed for MySQL 5.6+
  413. // and MariaDB 10.0+
  414. if (isset($col['default'])
  415. && $col['default'] == 'CURRENT_TIMESTAMP'
  416. && $version < 50605) {
  417. $col['type'] = 'timestamp';
  418. }
  419. }
  420. $col['type'] = $this->mapType($col);
  421. unset($col['size']);
  422. }
  423. if (!common_config('db', 'mysql_foreign_keys')) {
  424. unset($tableDef['foreign keys']);
  425. }
  426. return $tableDef;
  427. }
  428. }