Merge branch 'wip_MDL-46235_m28_innodbtext' of https://github.com/skodak/moodle

This commit is contained in:
Damyon Wiese 2014-08-26 12:28:47 +08:00
commit 112632ed58
4 changed files with 478 additions and 0 deletions

View file

@ -0,0 +1,202 @@
<?php
// This file is part of Moodle - http://moodle.org/
//
// Moodle is free software: you can redistribute it and/or modify
// it under the terms of the GNU General Public License as published by
// the Free Software Foundation, either version 3 of the License, or
// (at your option) any later version.
//
// Moodle is distributed in the hope that it will be useful,
// but WITHOUT ANY WARRANTY; without even the implied warranty of
// MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
// GNU General Public License for more details.
//
// You should have received a copy of the GNU General Public License
// along with Moodle. If not, see <http://www.gnu.org/licenses/>.
/**
* MySQL table row compression tool tool.
*
* @package core
* @copyright 2014 Totara Learning Solutions Ltd {@link http://www.totaralms.com/}
* @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
* @author Petr Skoda <petr.skoda@totaralms.com>
*/
define('CLI_SCRIPT', true);
require(dirname(__FILE__).'/../../config.php');
require_once($CFG->libdir . '/clilib.php');
if ($DB->get_dbfamily() !== 'mysql') {
cli_error('This script is used for MySQL databases only.');
}
$engine = strtolower($DB->get_dbengine());
if ($engine !== 'innodb' and $engine !== 'xtradb') {
cli_error('This script is for MySQL servers using InnoDB or XtraDB engines only.');
}
list($options, $unrecognized) = cli_get_params(
array('help' => false, 'info' => false, 'list' => false, 'fix' => false, 'showsql' => false),
array('h' => 'help', 'i' => 'info', 'l' => 'list', 'f' => 'fix', 's' => 'showsql')
);
if ($unrecognized) {
$unrecognized = implode("\n ", $unrecognized);
cli_error(get_string('cliunknowoption', 'admin', $unrecognized));
}
$help =
"Script for detection of row size problems in MySQL InnoDB tables.
By default InnoDB storage table is using legacy Antelope file format
which has major restriction on database row size.
Use this script to detect and fix database tables with potentail data
overflow problems.
Options:
-i, --info Show database information
-l, --list List problematic tables
-f, --fix Attempt to fix all tables (requires SUPER privilege)
-s, --showsql Print SQL statements for fixing of tables
-h, --help Print out this help
Example:
\$ sudo -u www-data /usr/bin/php admin/cli/mysql_compressed_rows.php -l
";
/** @var mysql_sql_generator $generator */
$generator = $DB->get_manager()->generator;
$info = $DB->get_server_info();
$filepertable = $DB->get_record_sql("SHOW VARIABLES LIKE 'innodb_file_per_table'");
$filepertable = $filepertable ? $filepertable->value : '';
$fileformat = $DB->get_record_sql("SHOW VARIABLES LIKE 'innodb_file_format'");
$fileformat = $fileformat ? $fileformat->value : '';
$prefix = $DB->get_prefix();
$database = $CFG->dbname;
if (!empty($options['info'])) {
echo "Database version: " . $info['description'] . "\n";
echo "Database name: $database\n";
echo "Database engine: " . $DB->get_dbengine() . "\n";
echo "innodb_file_per_table: $filepertable\n";
echo "innodb_file_format: $fileformat\n";
exit(0);
} else if (!empty($options['list'])) {
$problem = false;
foreach ($DB->get_tables(false) as $table) {
$columns = $DB->get_columns($table, false);
$size = $generator->guess_antolope_row_size($columns);
$format = $DB->get_row_format($table);
if ($size <= $generator::ANTELOPE_MAX_ROW_SIZE) {
continue;
}
echo str_pad($prefix . $table, 32, ' ', STR_PAD_RIGHT);
echo str_pad($format, 11, ' ', STR_PAD_RIGHT);
if ($format === 'Compact' or $format === 'Redundant') {
$problem = true;
echo " (needs fixing)\n";
} else if ($format !== 'Compressed' and $format !== 'Dynamic') {
echo " (unknown)\n";
} else {
echo "\n";
}
}
if ($problem) {
exit(1);
}
exit(0);
} else if (!empty($options['fix'])) {
$fixtables = array();
foreach ($DB->get_tables(false) as $table) {
$columns = $DB->get_columns($table, false);
$size = $generator->guess_antolope_row_size($columns);
$format = $DB->get_row_format($table);
if ($size <= $generator::ANTELOPE_MAX_ROW_SIZE) {
continue;
}
if ($format === 'Compact' or $format === 'Redundant') {
$fixtables[$table] = $table;
}
}
if (!$fixtables) {
echo "No changes necessary\n";
exit(0);
}
if ($filepertable !== 'ON') {
try {
$DB->execute("SET GLOBAL innodb_file_per_table=1");
} catch (dml_exception $e) {
echo "Cannot enable GLOBAL innodb_file_per_table setting, use --sqhowsql option and execute the statements manually.";
throw $e;
}
}
if ($fileformat !== 'Barracuda') {
try {
$DB->execute("SET GLOBAL innodb_file_format=Barracuda");
} catch (dml_exception $e) {
echo "Cannot change GLOBAL innodb_file_format setting, use --sqhowsql option and execute the statements manually.";
throw $e;
}
}
if (!$DB->is_compressed_row_format_supported(false)) {
echo "MySQL server is not compatible with compressed row format.";
exit(1);
}
foreach ($fixtables as $table) {
$DB->change_database_structure("ALTER TABLE {$prefix}$table ROW_FORMAT=Compressed");
echo str_pad($prefix . $table, 32, ' ', STR_PAD_RIGHT) . " ... Compressed\n";
}
exit(0);
} else if (!empty($options['showsql'])) {
$fixtables = array();
foreach ($DB->get_tables(false) as $table) {
$columns = $DB->get_columns($table, false);
$size = $generator->guess_antolope_row_size($columns);
$format = $DB->get_row_format($table);
if ($size <= $generator::ANTELOPE_MAX_ROW_SIZE) {
continue;
}
if ($format === 'Compact' or $format === 'Redundant') {
$fixtables[$table] = $table;
}
}
if (!$fixtables) {
echo "No changes necessary\n";
exit(0);
}
echo "Copy the following SQL statements and execute them using account with SUPER privilege:\n\n";
echo "USE $database;\n";
echo "SET SESSION sql_mode=STRICT_ALL_TABLES;\n";
echo "SET GLOBAL innodb_file_per_table=1;\n";
echo "SET GLOBAL innodb_file_format=Barracuda;\n";
foreach ($fixtables as $table) {
echo "ALTER TABLE {$prefix}$table ROW_FORMAT=Compressed;\n";
}
echo "\n";
exit(0);
} else {
echo $help;
die;
}

View file

@ -88,6 +88,9 @@ class mysql_sql_generator extends sql_generator {
/** @var string SQL sentence to rename one key 'TABLENAME', 'OLDKEYNAME' and 'NEWKEYNAME' are dynamically replaced.*/
public $rename_key_sql = null;
/** Maximum size of InnoDB row in Antelope file format */
const ANTELOPE_MAX_ROW_SIZE = 8126;
/**
* Reset a sequence to the id field of a table.
*
@ -108,6 +111,78 @@ class mysql_sql_generator extends sql_generator {
return array("ALTER TABLE $this->prefix$tablename AUTO_INCREMENT = $value");
}
/**
* Calculate proximate row size when using InnoDB
* tables in Antelope row format.
*
* Note: the returned value is a bit higher to compensate for
* errors and changes of column data types.
*
* @param xmldb_field[]|database_column_info[] $columns
* @return int approximate row size in bytes
*/
public function guess_antolope_row_size(array $columns) {
if (empty($columns)) {
return 0;
}
$size = 0;
$first = reset($columns);
if (count($columns) > 1) {
// Do not start with zero because we need to cover changes of field types and
// this calculation is most probably not be accurate.
$size += 1000;
}
if ($first instanceof xmldb_field) {
foreach ($columns as $field) {
switch ($field->getType()) {
case XMLDB_TYPE_TEXT:
$size += 768;
break;
case XMLDB_TYPE_BINARY:
$size += 768;
break;
case XMLDB_TYPE_CHAR:
$bytes = $field->getLength() * 3;
if ($bytes > 768) {
$bytes = 768;
}
$size += $bytes;
break;
default:
// Anything else is usually maximum 8 bytes.
$size += 8;
}
}
} else if ($first instanceof database_column_info) {
foreach ($columns as $column) {
switch ($column->meta_type) {
case 'X':
$size += 768;
break;
case 'B':
$size += 768;
break;
case 'C':
$bytes = $column->max_length * 3;
if ($bytes > 768) {
$bytes = 768;
}
$size += $bytes;
break;
default:
// Anything else is usually maximum 8 bytes.
$size += 8;
}
}
}
return $size;
}
/**
* Given one correct xmldb_table, returns the SQL statements
* to create it (inside one array).
@ -122,6 +197,15 @@ class mysql_sql_generator extends sql_generator {
// Do we know collation?
$collation = $this->mdb->get_dbcollation();
// Do we need to use compressed format for rows?
$rowformat = "";
$size = $this->guess_antolope_row_size($xmldb_table->getFields());
if ($size > self::ANTELOPE_MAX_ROW_SIZE) {
if ($this->mdb->is_compressed_row_format_supported()) {
$rowformat = "\n ROW_FORMAT=Compressed";
}
}
$sqlarr = parent::getCreateTableSQL($xmldb_table);
// This is a very nasty hack that tries to use just one query per created table
@ -144,6 +228,9 @@ class mysql_sql_generator extends sql_generator {
}
$sql .= "\n DEFAULT COLLATE = $collation";
}
if ($rowformat) {
$sql .= $rowformat;
}
$sqls[] = $sql;
continue;
}
@ -186,6 +273,39 @@ class mysql_sql_generator extends sql_generator {
return $sqls;
}
/**
* Given one xmldb_table and one xmldb_field, return the SQL statements needed to add the field to the table.
*
* @param xmldb_table $xmldb_table The table related to $xmldb_field.
* @param xmldb_field $xmldb_field The instance of xmldb_field to create the SQL from.
* @param string $skip_type_clause The type clause on alter columns, NULL by default.
* @param string $skip_default_clause The default clause on alter columns, NULL by default.
* @param string $skip_notnull_clause The null/notnull clause on alter columns, NULL by default.
* @return array The SQL statement for adding a field to the table.
*/
public function getAddFieldSQL($xmldb_table, $xmldb_field, $skip_type_clause = NULL, $skip_default_clause = NULL, $skip_notnull_clause = NULL) {
$sqls = parent::getAddFieldSQL($xmldb_table, $xmldb_field, $skip_type_clause, $skip_default_clause, $skip_notnull_clause);
if ($this->table_exists($xmldb_table)) {
$tablename = $xmldb_table->getName();
$size = $this->guess_antolope_row_size($this->mdb->get_columns($tablename));
$size += $this->guess_antolope_row_size(array($xmldb_field));
if ($size > self::ANTELOPE_MAX_ROW_SIZE) {
if ($this->mdb->is_compressed_row_format_supported()) {
$format = strtolower($this->mdb->get_row_format($tablename));
if ($format === 'compact' or $format === 'redundant') {
// Change the format before conversion so that we do not run out of space.
array_unshift($sqls, "ALTER TABLE {$this->prefix}$tablename ROW_FORMAT=Compressed");
}
}
}
}
return $sqls;
}
/**
* Given one correct xmldb_table, returns the SQL statements
* to create temporary table (inside one array).

View file

@ -508,6 +508,93 @@ class core_ddl_testcase extends database_driver_testcase {
}
}
/**
* Test if database supports tables with many TEXT fields,
* InnoDB is known to failed during data insertion instead
* of table creation when text fields contain actual data.
*/
public function test_row_size_limits() {
$DB = $this->tdb; // Do not use global $DB!
$dbman = $this->tdb->get_manager();
$text = str_repeat('š', 1333);
$data = new stdClass();
$data->name = 'test';
$table = new xmldb_table('test_innodb');
$table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$table->add_field('name', XMLDB_TYPE_CHAR, '30', null, null, null, null);
$table->add_key('primary', XMLDB_KEY_PRIMARY, array('id'));
for ($i = 0; $i < 20; $i++) {
$table->add_field('text'.$i, XMLDB_TYPE_TEXT, null, null, null, null, null);
$data->{'text'.$i} = $text;
}
$dbman->create_table($table);
try {
$id = $DB->insert_record('test_innodb', $data);
$expected = (array)$data;
$expected['id'] = (string)$id;
$this->assertEquals($expected, (array)$DB->get_record('test_innodb', array('id' => $id)), '', 0, 10, true);
} catch (dml_exception $e) {
// Give some nice error message when known problematic MySQL with InnoDB detected.
if ($DB->get_dbfamily() === 'mysql') {
$engine = strtolower($DB->get_dbengine());
if ($engine === 'innodb' or $engine === 'xtradb') {
if (!$DB->is_compressed_row_format_supported()) {
$this->fail("Row size limit reached in MySQL using InnoDB, configure server to use innodb_file_format=Barracuda and innodb_file_per_table=1");
}
}
}
throw $e;
}
$dbman->drop_table($table);
$data = new stdClass();
$data->name = 'test';
$table = new xmldb_table('test_innodb');
$table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$table->add_field('name', XMLDB_TYPE_CHAR, '30', null, null, null, null);
$table->add_key('primary', XMLDB_KEY_PRIMARY, array('id'));
$dbman->create_table($table);
$DB->insert_record('test_innodb', array('name' => 'test'));
for ($i = 0; $i < 20; $i++) {
$field = new xmldb_field('text'.$i, XMLDB_TYPE_TEXT, null, null, null, null, null);
$dbman->add_field($table, $field);
$data->{'text'.$i} = $text;
$id = $DB->insert_record('test_innodb', $data);
$expected = (array)$data;
$expected['id'] = (string)$id;
$this->assertEquals($expected, (array)$DB->get_record('test_innodb', array('id' => $id)), '', 0, 10, true);
}
$dbman->drop_table($table);
// MySQL VARCHAR fields may hit a different 65535 row size limit when creating tables.
$data = new stdClass();
$data->name = 'test';
$table = new xmldb_table('test_innodb');
$table->add_field('id', XMLDB_TYPE_INTEGER, '10', null, XMLDB_NOTNULL, XMLDB_SEQUENCE, null);
$table->add_field('name', XMLDB_TYPE_CHAR, '30', null, null, null, null);
$table->add_key('primary', XMLDB_KEY_PRIMARY, array('id'));
for ($i = 0; $i < 15; $i++) {
$table->add_field('text'.$i, XMLDB_TYPE_CHAR, '1333', null, null, null, null);
$data->{'text'.$i} = $text;
}
$dbman->create_table($table);
$id = $DB->insert_record('test_innodb', $data);
$expected = (array)$data;
$expected['id'] = (string)$id;
$this->assertEquals($expected, (array)$DB->get_record('test_innodb', array('id' => $id)), '', 0, 10, true);
$dbman->drop_table($table);
}
/**
* Test behaviour of drop_table()
*/

View file

@ -39,6 +39,8 @@ class mysqli_native_moodle_database extends moodle_database {
/** @var mysqli $mysqli */
protected $mysqli = null;
/** @var bool is compressed row format supported cache */
protected $compressedrowformatsupported = null;
private $transactions_supported = null;
@ -280,6 +282,73 @@ class mysqli_native_moodle_database extends moodle_database {
return $collation;
}
/**
* Get the row format from the database schema.
*
* @param string $table
* @return string row_format name or null if not known or table does not exist.
*/
public function get_row_format($table) {
$rowformat = null;
$table = $this->mysqli->real_escape_string($table);
$sql = "SELECT row_format
FROM INFORMATION_SCHEMA.TABLES
WHERE table_schema = DATABASE() AND table_name = '{$this->prefix}$table'";
$this->query_start($sql, NULL, SQL_QUERY_AUX);
$result = $this->mysqli->query($sql);
$this->query_end($result);
if ($rec = $result->fetch_assoc()) {
$rowformat = $rec['row_format'];
}
$result->close();
return $rowformat;
}
/**
* Is this database compatible with compressed row format?
* This feature is necessary for support of large number of text
* columns in InnoDB/XtraDB database.
*
* @param bool $cached use cached result
* @return bool true if table can be created or changed to compressed row format.
*/
public function is_compressed_row_format_supported($cached = true) {
if ($cached and isset($this->compressedrowformatsupported)) {
return($this->compressedrowformatsupported);
}
$engine = strtolower($this->get_dbengine());
$info = $this->get_server_info();
if (version_compare($info['version'], '5.5.0') < 0) {
// MySQL 5.1 is not supported here because we cannot read the file format.
$this->compressedrowformatsupported = false;
} else if ($engine !== 'innodb' and $engine !== 'xtradb') {
// Other engines are not supported, most probably not compatible.
$this->compressedrowformatsupported = false;
} else if (!$filepertable = $this->get_record_sql("SHOW VARIABLES LIKE 'innodb_file_per_table'")) {
$this->compressedrowformatsupported = false;
} else if ($filepertable->value !== 'ON') {
$this->compressedrowformatsupported = false;
} else if (!$fileformat = $this->get_record_sql("SHOW VARIABLES LIKE 'innodb_file_format'")) {
$this->compressedrowformatsupported = false;
} else if ($fileformat->value !== 'Barracuda') {
$this->compressedrowformatsupported = false;
} else {
// All the tests passed, we can safely use ROW_FORMAT=Compressed in sql statements.
$this->compressedrowformatsupported = true;
}
return $this->compressedrowformatsupported;
}
/**
* Returns localised database type name
* Note: can be used before connect()