Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP
Browse files

Merge branch 'w29_MDL-34271_m22_mysqlcollation' of git://github.com/s…

…kodak/moodle into MOODLE_22_STABLE
  • Loading branch information...
commit 091c72538242e73f745549cab49d9a7f22821efc 2 parents 62b4880 + 397cbe0
@danpoltawski danpoltawski authored
View
211 admin/cli/mysql_collation.php
@@ -0,0 +1,211 @@
+<?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 collation conversion tool.
+ *
+ * @package core
+ * @copyright 2012 Petr Skoda (http://skodak.org)
+ * @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
+ */
+
+define('CLI_SCRIPT', true);
+
+require(dirname(dirname(dirname(__FILE__))).'/config.php');
+require_once($CFG->libdir.'/clilib.php'); // cli only functions
+
+if ($DB->get_dbfamily() !== 'mysql') {
+ cli_error('This function is designed for MySQL databases only!');
+}
+
+// now get cli options
+list($options, $unrecognized) = cli_get_params(array('help'=>false, 'list'=>false, 'collation'=>false, 'available'=>false),
+ array('h'=>'help', 'l'=>'list', 'a'=>'available'));
+
+if ($unrecognized) {
+ $unrecognized = implode("\n ", $unrecognized);
+ cli_error(get_string('cliunknowoption', 'admin', $unrecognized));
+}
+
+$help =
+ "MySQL collation conversions script.
+
+It is strongly recommended to stop the web server before the conversion.
+This script may be executed before the main upgrade - 1.9.x data for example.
+
+Options:
+--collation=COLLATION Convert MySQL tables to different collation
+-l, --list Show table and column information
+-a, --available Show list of available collations
+-h, --help Print out this help
+
+Example:
+\$ sudo -u www-data /usr/bin/php admin/cli/mysql_collation.php --collation=utf8_general_ci
+";
+
+if (!empty($options['collation'])) {
+ $collations = mysql_get_collations();
+ $collation = clean_param($options['collation'], PARAM_ALPHANUMEXT);
+ $collation = strtolower($collation);
+ if (!isset($collations[$collation])) {
+ cli_error("Error: collation '$collation' is not available on this server!");
+ }
+
+ echo "Converting tables and columns to '$collation' for $CFG->wwwroot:\n";
+ $prefix = $DB->get_prefix();
+ $prefix = str_replace('_', '\\_', $prefix);
+ $sql = "SHOW TABLE STATUS WHERE Name LIKE BINARY '$prefix%'";
+ $rs = $DB->get_recordset_sql($sql);
+ $converted = 0;
+ $skipped = 0;
+ $errors = 0;
+ foreach ($rs as $table) {
+ echo str_pad($table->name, 40). " - ";
+
+ if ($table->collation === $collation) {
+ echo "NO CHANGE\n";
+ $skipped++;
+
+ } else {
+ $DB->change_database_structure("ALTER TABLE $table->name DEFAULT COLLATE = $collation");
+ echo "CONVERTED\n";
+ $converted++;
+ }
+
+ $sql = "SHOW FULL COLUMNS FROM $table->name WHERE collation IS NOT NULL";
+ $rs2 = $DB->get_recordset_sql($sql);
+ foreach ($rs2 as $column) {
+ $column = (object)array_change_key_case((array)$column, CASE_LOWER);
+ echo ' '.str_pad($column->field, 36). " - ";
+ if ($column->collation === $collation) {
+ echo "NO CHANGE\n";
+ $skipped++;
+ continue;
+ }
+
+ if ($column->type === 'tinytext' or $column->type === 'mediumtext' or $column->type === 'text' or $column->type === 'longtext') {
+ $notnull = ($column->null === 'NO') ? 'NOT NULL' : 'NULL';
+ $default = (!is_null($column->default) and $column->default !== '') ? "DEFAULT '$column->default'" : '';
+ // primary, unique and inc are not supported for texts
+ $sql = "ALTER TABLE $table->name MODIFY COLUMN $column->field $column->type COLLATE $collation $notnull $default";
+ $DB->change_database_structure($sql);
+
+ } else if (strpos($column->type, 'varchar') === 0) {
+ $notnull = ($column->null === 'NO') ? 'NOT NULL' : 'NULL';
+ $default = !is_null($column->default) ? "DEFAULT '$column->default'" : '';
+ // primary, unique and inc are not supported for texts
+ $sql = "ALTER TABLE $table->name MODIFY COLUMN $column->field $column->type COLLATE $collation $notnull $default";
+ $DB->change_database_structure($sql);
+ } else {
+ echo "ERROR (unknown column type: $column->type)\n";
+ $error++;
+ continue;
+ }
+ echo "CONVERTED\n";
+ $converted++;
+ }
+ $rs2->close();
+ }
+ $rs->close();
+ echo "Converted: $converted, skipped: $skipped, errors: $errors\n";
+ exit(0); // success
+
+} else if (!empty($options['list'])) {
+ echo "List of tables for $CFG->wwwroot:\n";
+ $prefix = $DB->get_prefix();
+ $prefix = str_replace('_', '\\_', $prefix);
+ $sql = "SHOW TABLE STATUS WHERE Name LIKE BINARY '$prefix%'";
+ $rs = $DB->get_recordset_sql($sql);
+ $counts = array();
+ foreach ($rs as $table) {
+ if (isset($counts[$table->collation])) {
+ $counts[$table->collation]++;
+ } else {
+ $counts[$table->collation] = 1;
+ }
+ echo str_pad($table->name, 40);
+ echo $table->collation. "\n";
+ $collations = mysql_get_column_collations($table->name);
+ foreach ($collations as $columname=>$collation) {
+ if (isset($counts[$collation])) {
+ $counts[$collation]++;
+ } else {
+ $counts[$collation] = 1;
+ }
+ echo ' ';
+ echo str_pad($columname, 36);
+ echo $collation. "\n";
+ }
+ }
+ $rs->close();
+
+ echo "\n";
+ echo "Table collations summary for $CFG->wwwroot:\n";
+ foreach ($counts as $collation => $count) {
+ echo "$collation: $count\n";
+ }
+ exit(0); // success
+
+} else if (!empty($options['available'])) {
+ echo "List of available MySQL collations for $CFG->wwwroot:\n";
+ $collations = mysql_get_collations();
+ foreach ($collations as $collation) {
+ echo " $collation\n";
+ }
+ die;
+
+} else {
+ echo $help;
+ die;
+}
+
+
+
+// ========== Some functions ==============
+
+function mysql_get_collations() {
+ global $DB;
+
+ $collations = array();
+ $sql = "SHOW COLLATION WHERE Collation LIKE 'utf8\_%' AND Charset = 'utf8'";
+ $rs = $DB->get_recordset_sql($sql);
+ foreach ($rs as $collation) {
+ $collations[$collation->collation] = $collation->collation;
+ }
+ $rs->close();
+
+ $collation = $DB->get_dbcollation();
+ if (isset($collations[$collation])) {
+ $collations[$collation] .= ' (default)';
+ }
+
+ return $collations;
+}
+
+function mysql_get_column_collations($tablename) {
+ global $DB;
+
+ $collations = array();
+ $sql = "SELECT column_name, collation_name
+ FROM INFORMATION_SCHEMA.COLUMNS
+ WHERE table_schema = DATABASE() AND table_name = ? AND collation_name IS NOT NULL";
+ $rs = $DB->get_recordset_sql($sql, array($tablename));
+ foreach($rs as $record) {
+ $collations[$record->column_name] = $record->collation_name;
+ }
+ $rs->close();
+ return $collations;
+}
View
70 lib/ddl/mysql_sql_generator.php
@@ -98,26 +98,32 @@ public function getResetSequenceSQL($table) {
/**
* Given one correct xmldb_table, returns the SQL statements
- * to create it (inside one array)
+ * to create it (inside one array).
+ *
+ * @param xmldb_table $xmldb_table An xmldb_table instance.
+ * @return array An array of SQL statements, starting with the table creation SQL followed
+ * by any of its comments, indexes and sequence creation SQL statements.
*/
public function getCreateTableSQL($xmldb_table) {
- // first find out if want some special db engine
- $engine = null;
- if (method_exists($this->mdb, 'get_dbengine')) {
- $engine = $this->mdb->get_dbengine();
- }
+ // First find out if want some special db engine.
+ $engine = $this->mdb->get_dbengine();
+ // Do we know collation?
+ $collation = $this->mdb->get_dbcollation();
$sqlarr = parent::getCreateTableSQL($xmldb_table);
- if (!$engine) {
- // we rely on database defaults
- return $sqlarr;
- }
-
- // let's inject the engine into SQL
+ // Let's inject the extra MySQL tweaks.
foreach ($sqlarr as $i=>$sql) {
if (strpos($sql, 'CREATE TABLE ') === 0) {
- $sqlarr[$i] .= " ENGINE = $engine";
+ if ($engine) {
+ $sqlarr[$i] .= " ENGINE = $engine";
+ }
+ if ($collation) {
+ if (strpos($collation, 'utf8_') === 0) {
+ $sqlarr[$i] .= " DEFAULT CHARACTER SET utf8";
+ }
+ $sqlarr[$i] .= " DEFAULT COLLATE = $collation";
+ }
}
}
@@ -126,12 +132,32 @@ public function getCreateTableSQL($xmldb_table) {
/**
* Given one correct xmldb_table, returns the SQL statements
- * to create temporary table (inside one array)
+ * to create temporary table (inside one array).
+ *
+ * @param xmldb_table $xmldb_table The xmldb_table object instance.
+ * @return array of sql statements
*/
public function getCreateTempTableSQL($xmldb_table) {
+ // Do we know collation?
+ $collation = $this->mdb->get_dbcollation();
$this->temptables->add_temptable($xmldb_table->getName());
- $sqlarr = parent::getCreateTableSQL($xmldb_table); // we do not want the engine hack included in create table SQL
- $sqlarr = preg_replace('/^CREATE TABLE (.*)/s', 'CREATE TEMPORARY TABLE $1', $sqlarr);
+
+ $sqlarr = parent::getCreateTableSQL($xmldb_table);
+
+ // Let's inject the extra MySQL tweaks.
+ foreach ($sqlarr as $i=>$sql) {
+ if (strpos($sql, 'CREATE TABLE ') === 0) {
+ // We do not want the engine hack included in create table SQL.
+ $sqlarr[$i] = preg_replace('/^CREATE TABLE (.*)/s', 'CREATE TEMPORARY TABLE $1', $sql);
+ if ($collation) {
+ if (strpos($collation, 'utf8_') === 0) {
+ $sqlarr[$i] .= " DEFAULT CHARACTER SET utf8";
+ }
+ $sqlarr[$i] .= " DEFAULT COLLATE $collation";
+ }
+ }
+ }
+
return $sqlarr;
}
@@ -202,6 +228,12 @@ public function getTypeSQL($xmldb_type, $xmldb_length=null, $xmldb_decimals=null
$xmldb_length='255';
}
$dbtype .= '(' . $xmldb_length . ')';
+ if ($collation = $this->mdb->get_dbcollation()) {
+ if (strpos($collation, 'utf8_') === 0) {
+ $dbtype .= " CHARACTER SET utf8";
+ }
+ $dbtype .= " COLLATE $collation";
+ }
break;
case XMLDB_TYPE_TEXT:
if (empty($xmldb_length)) {
@@ -214,6 +246,12 @@ public function getTypeSQL($xmldb_type, $xmldb_length=null, $xmldb_decimals=null
} else {
$dbtype = 'LONGTEXT';
}
+ if ($collation = $this->mdb->get_dbcollation()) {
+ if (strpos($collation, 'utf8_') === 0) {
+ $dbtype .= " CHARACTER SET utf8";
+ }
+ $dbtype .= " COLLATE $collation";
+ }
break;
case XMLDB_TYPE_BINARY:
if (empty($xmldb_length)) {
View
106 lib/dml/mysqli_native_moodle_database.php
@@ -81,7 +81,13 @@ public function create_database($dbhost, $dbuser, $dbpass, $dbname, array $dbopt
throw new dml_connection_exception($dberr);
}
- $result = $conn->query("CREATE DATABASE $dbname DEFAULT CHARACTER SET utf8 COLLATE utf8_unicode_ci");
+ if (isset($dboptions['dbcollation']) and strpos($dboptions['dbcollation'], 'utf8_') === 0) {
+ $collation = $dboptions['dbcollation'];
+ } else {
+ $collation = 'utf8_unicode_ci';
+ }
+
+ $result = $conn->query("CREATE DATABASE $dbname DEFAULT CHARACTER SET utf8 DEFAULT COLLATE ".$collation);
$conn->close();
@@ -145,22 +151,28 @@ public function get_dbengine() {
return $this->dboptions['dbengine'];
}
+ if ($this->external) {
+ return null;
+ }
+
$engine = null;
- if (!$this->external) {
- // look for current engine of our config table (the first table that gets created),
- // so that we create all tables with the same engine
- $sql = "SELECT engine FROM INFORMATION_SCHEMA.TABLES WHERE table_schema = DATABASE() AND table_name = '{$this->prefix}config'";
- $this->query_start($sql, NULL, SQL_QUERY_AUX);
- $result = $this->mysqli->query($sql);
- $this->query_end($result);
- if ($rec = $result->fetch_assoc()) {
- $engine = $rec['engine'];
- }
- $result->close();
+ // Look for current engine of our config table (the first table that gets created),
+ // so that we create all tables with the same engine.
+ $sql = "SELECT engine
+ FROM INFORMATION_SCHEMA.TABLES
+ WHERE table_schema = DATABASE() AND table_name = '{$this->prefix}config'";
+ $this->query_start($sql, NULL, SQL_QUERY_AUX);
+ $result = $this->mysqli->query($sql);
+ $this->query_end($result);
+ if ($rec = $result->fetch_assoc()) {
+ $engine = $rec['engine'];
}
+ $result->close();
if ($engine) {
+ // Cache the result to improve performance.
+ $this->dboptions['dbengine'] = $engine;
return $engine;
}
@@ -174,7 +186,7 @@ public function get_dbengine() {
}
$result->close();
- if (!$this->external and $engine === 'MyISAM') {
+ if ($engine === 'MyISAM') {
// we really do not want MyISAM for Moodle, InnoDB or XtraDB is a reasonable defaults if supported
$sql = "SHOW STORAGE ENGINES";
$this->query_start($sql, NULL, SQL_QUERY_AUX);
@@ -195,10 +207,78 @@ public function get_dbengine() {
}
}
+ // Cache the result to improve performance.
+ $this->dboptions['dbengine'] = $engine;
return $engine;
}
/**
+ * Returns the current MySQL db collation.
+ *
+ * This is an ugly workaround for MySQL default collation problems.
+ *
+ * @return string or null MySQL collation name
+ */
+ public function get_dbcollation() {
+ if (isset($this->dboptions['dbcollation'])) {
+ return $this->dboptions['dbcollation'];
+ }
+ if ($this->external) {
+ return null;
+ }
+
+ $collation = null;
+
+ // Look for current collation of our config table (the first table that gets created),
+ // so that we create all tables with the same collation.
+ $sql = "SELECT collation_name
+ FROM INFORMATION_SCHEMA.COLUMNS
+ WHERE table_schema = DATABASE() AND table_name = '{$this->prefix}config' AND column_name = 'value'";
+ $this->query_start($sql, NULL, SQL_QUERY_AUX);
+ $result = $this->mysqli->query($sql);
+ $this->query_end($result);
+ if ($rec = $result->fetch_assoc()) {
+ $collation = $rec['collation_name'];
+ }
+ $result->close();
+
+ if (!$collation) {
+ // Get the default database collation, but only if using UTF-8.
+ $sql = "SELECT @@collation_database";
+ $this->query_start($sql, NULL, SQL_QUERY_AUX);
+ $result = $this->mysqli->query($sql);
+ $this->query_end($result);
+ if ($rec = $result->fetch_assoc()) {
+ if (strpos($rec['@@collation_database'], 'utf8_') === 0) {
+ $collation = $rec['@@collation_database'];
+ }
+ }
+ $result->close();
+ }
+
+ if (!$collation) {
+ // We want only utf8 compatible collations.
+ $collation = null;
+ $sql = "SHOW COLLATION WHERE Collation LIKE 'utf8\_%' AND Charset = 'utf8'";
+ $this->query_start($sql, NULL, SQL_QUERY_AUX);
+ $result = $this->mysqli->query($sql);
+ $this->query_end($result);
+ while ($res = $result->fetch_assoc()) {
+ $collation = $res['Collation'];
+ if (strtoupper($res['Default']) === 'YES') {
+ $collation = $res['Collation'];
+ break;
+ }
+ }
+ $result->close();
+ }
+
+ // Cache the result to improve performance.
+ $this->dboptions['dbcollation'] = $collation;
+ return $collation;
+ }
+
+ /**
* Returns localised database type name
* Note: can be used before connect()
* @return string
Please sign in to comment.
Something went wrong with that request. Please try again.