mirror of
https://github.com/Combodo/iTop.git
synced 2026-02-13 07:24:13 +01:00
N°1001 setup : database/tables/columns charset and collation conversion
* check DB charset/collation and do conversion if needed * same for existing tables * add both info in fields signatures, so that conversions will be trigerred if needed SVN:trunk[5444]
This commit is contained in:
@@ -111,15 +111,6 @@ define('LINKSET_EDITMODE_ADDREMOVE', 4); // The "linked" objects can be added/re
|
||||
*/
|
||||
abstract class AttributeDefinition
|
||||
{
|
||||
/**
|
||||
* SQL charset & collation declaration for text columns
|
||||
*
|
||||
* @see https://dev.mysql.com/doc/refman/5.7/en/charset-column.html
|
||||
* @since 2.5 #1001 switch to utf8mb4
|
||||
*/
|
||||
const SQL_TEXT_COLUMNS_CHARSET = ' CHARACTER SET '.DEFAULT_CHARACTER_SET.' COLLATE '.DEFAULT_COLLATION;
|
||||
|
||||
|
||||
public function GetType()
|
||||
{
|
||||
return Dict::S('Core:'.get_class($this));
|
||||
@@ -1503,7 +1494,7 @@ class AttributeDBFieldVoid extends AttributeDefinition
|
||||
protected function GetSQLCol($bFullSpec = false)
|
||||
{
|
||||
return 'VARCHAR(255)'
|
||||
.self::SQL_TEXT_COLUMNS_CHARSET
|
||||
.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION
|
||||
.($bFullSpec ? $this->GetSQLColSpec() : '');
|
||||
}
|
||||
protected function GetSQLColSpec()
|
||||
@@ -2118,7 +2109,7 @@ class AttributeString extends AttributeDBField
|
||||
protected function GetSQLCol($bFullSpec = false)
|
||||
{
|
||||
return 'VARCHAR(255)'
|
||||
.self::SQL_TEXT_COLUMNS_CHARSET
|
||||
.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION
|
||||
.($bFullSpec ? $this->GetSQLColSpec() : '');
|
||||
}
|
||||
|
||||
@@ -2510,7 +2501,7 @@ class AttributePassword extends AttributeString
|
||||
protected function GetSQLCol($bFullSpec = false)
|
||||
{
|
||||
return "VARCHAR(64)"
|
||||
.self::SQL_TEXT_COLUMNS_CHARSET
|
||||
.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION
|
||||
.($bFullSpec ? $this->GetSQLColSpec() : '');
|
||||
}
|
||||
|
||||
@@ -2641,7 +2632,7 @@ class AttributeText extends AttributeString
|
||||
|
||||
protected function GetSQLCol($bFullSpec = false)
|
||||
{
|
||||
return "TEXT".self::SQL_TEXT_COLUMNS_CHARSET;
|
||||
return "TEXT".CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION;
|
||||
}
|
||||
|
||||
public function GetSQLColumns($bFullSpec = false)
|
||||
@@ -2651,7 +2642,7 @@ class AttributeText extends AttributeString
|
||||
if ($this->GetOptional('format', null) != null )
|
||||
{
|
||||
// Add the extra column only if the property 'format' is specified for the attribute
|
||||
$aColumns[$this->Get('sql').'_format'] = "ENUM('text','html')".self::SQL_TEXT_COLUMNS_CHARSET;
|
||||
$aColumns[$this->Get('sql').'_format'] = "ENUM('text','html')".CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION;
|
||||
if ($bFullSpec)
|
||||
{
|
||||
$aColumns[$this->Get('sql').'_format'].= " DEFAULT 'text'"; // default 'text' is for migrating old records
|
||||
@@ -2975,7 +2966,7 @@ class AttributeLongText extends AttributeText
|
||||
{
|
||||
protected function GetSQLCol($bFullSpec = false)
|
||||
{
|
||||
return "LONGTEXT".self::SQL_TEXT_COLUMNS_CHARSET;
|
||||
return "LONGTEXT".CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION;
|
||||
}
|
||||
|
||||
public function GetMaxSize()
|
||||
@@ -3155,7 +3146,7 @@ class AttributeCaseLog extends AttributeLongText
|
||||
{
|
||||
$aColumns = array();
|
||||
$aColumns[$this->GetCode()] = 'LONGTEXT' // 2^32 (4 Gb)
|
||||
.self::SQL_TEXT_COLUMNS_CHARSET;
|
||||
.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION;
|
||||
$aColumns[$this->GetCode().'_index'] = 'BLOB';
|
||||
return $aColumns;
|
||||
}
|
||||
@@ -3499,13 +3490,13 @@ class AttributeEnum extends AttributeString
|
||||
// make sure that this string will match the field type returned by the DB
|
||||
// (used to perform a comparison between the current DB format and the data model)
|
||||
return "ENUM(".implode(",", $aValues).")"
|
||||
.self::SQL_TEXT_COLUMNS_CHARSET
|
||||
.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION
|
||||
.($bFullSpec ? $this->GetSQLColSpec() : '');
|
||||
}
|
||||
else
|
||||
{
|
||||
return "VARCHAR(255)"
|
||||
.self::SQL_TEXT_COLUMNS_CHARSET
|
||||
.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION
|
||||
.($bFullSpec ? " DEFAULT ''" : ""); // ENUM() is not an allowed syntax!
|
||||
}
|
||||
}
|
||||
@@ -5238,7 +5229,7 @@ class AttributeURL extends AttributeString
|
||||
protected function GetSQLCol($bFullSpec = false)
|
||||
{
|
||||
return "VARCHAR(2048)"
|
||||
.self::SQL_TEXT_COLUMNS_CHARSET
|
||||
.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION
|
||||
.($bFullSpec ? $this->GetSQLColSpec() : '');
|
||||
}
|
||||
|
||||
@@ -5413,8 +5404,8 @@ class AttributeBlob extends AttributeDefinition
|
||||
{
|
||||
$aColumns = array();
|
||||
$aColumns[$this->GetCode().'_data'] = 'LONGBLOB'; // 2^32 (4 Gb)
|
||||
$aColumns[$this->GetCode().'_mimetype'] = 'VARCHAR(255)'.self::SQL_TEXT_COLUMNS_CHARSET;
|
||||
$aColumns[$this->GetCode().'_filename'] = 'VARCHAR(255)'.self::SQL_TEXT_COLUMNS_CHARSET;
|
||||
$aColumns[$this->GetCode().'_mimetype'] = 'VARCHAR(255)'.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION;
|
||||
$aColumns[$this->GetCode().'_filename'] = 'VARCHAR(255)'.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION;
|
||||
return $aColumns;
|
||||
}
|
||||
|
||||
@@ -6551,7 +6542,7 @@ class AttributeOneWayPassword extends AttributeDefinition
|
||||
public function GetImportColumns()
|
||||
{
|
||||
$aColumns = array();
|
||||
$aColumns[$this->GetCode()] = 'TINYTEXT'.self::SQL_TEXT_COLUMNS_CHARSET;
|
||||
$aColumns[$this->GetCode()] = 'TINYTEXT'.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION;
|
||||
return $aColumns;
|
||||
}
|
||||
|
||||
@@ -6622,7 +6613,7 @@ class AttributeTable extends AttributeDBField
|
||||
|
||||
protected function GetSQLCol($bFullSpec = false)
|
||||
{
|
||||
return "LONGTEXT".self::SQL_TEXT_COLUMNS_CHARSET;
|
||||
return "LONGTEXT".CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION;
|
||||
}
|
||||
|
||||
public function GetMaxSize()
|
||||
@@ -7025,7 +7016,7 @@ class AttributeRedundancySettings extends AttributeDBField
|
||||
protected function GetSQLCol($bFullSpec = false)
|
||||
{
|
||||
return "VARCHAR(20)"
|
||||
.self::SQL_TEXT_COLUMNS_CHARSET
|
||||
.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION
|
||||
.($bFullSpec ? $this->GetSQLColSpec() : '');
|
||||
}
|
||||
|
||||
|
||||
@@ -108,6 +108,14 @@ class MySQLHasGoneAwayException extends MySQLException
|
||||
*/
|
||||
class CMDBSource
|
||||
{
|
||||
/**
|
||||
* SQL charset & collation declaration for text columns
|
||||
*
|
||||
* @see https://dev.mysql.com/doc/refman/5.7/en/charset-column.html
|
||||
* @since 2.5 #1001 switch to utf8mb4
|
||||
*/
|
||||
const SQL_STRING_COLUMNS_CHARSET_DEFINITION = ' CHARACTER SET '.DEFAULT_CHARACTER_SET.' COLLATE '.DEFAULT_COLLATION;
|
||||
|
||||
protected static $m_sDBHost;
|
||||
protected static $m_sDBUser;
|
||||
protected static $m_sDBPwd;
|
||||
@@ -906,11 +914,22 @@ class CMDBSource
|
||||
if (empty($aTableInfo)) return false;
|
||||
if (!array_key_exists($sField, $aTableInfo["Fields"])) return false;
|
||||
$aFieldData = $aTableInfo["Fields"][$sField];
|
||||
|
||||
$sRet = $aFieldData["Type"];
|
||||
|
||||
$sColumnCharset = $aFieldData["Charset"];
|
||||
$sColumnCollation = $aFieldData["Collation"];
|
||||
if (!empty($sColumnCharset))
|
||||
{
|
||||
$sRet .= ' CHARACTER SET '.$sColumnCharset;
|
||||
$sRet .= ' COLLATE '.$sColumnCollation;
|
||||
}
|
||||
|
||||
if ($aFieldData["Null"] == 'NO')
|
||||
{
|
||||
$sRet .= ' NOT NULL';
|
||||
}
|
||||
|
||||
if (is_numeric($aFieldData["Default"]))
|
||||
{
|
||||
if (strtolower(substr($aFieldData["Type"], 0, 5)) == 'enum(')
|
||||
@@ -928,6 +947,7 @@ class CMDBSource
|
||||
{
|
||||
$sRet .= ' DEFAULT '.self::Quote($aFieldData["Default"]);
|
||||
}
|
||||
|
||||
return $sRet;
|
||||
}
|
||||
|
||||
@@ -970,32 +990,34 @@ class CMDBSource
|
||||
private static function _TableInfoCacheInit($sTableName)
|
||||
{
|
||||
if (isset(self::$m_aTablesInfo[strtolower($sTableName)])
|
||||
&& (self::$m_aTablesInfo[strtolower($sTableName)] != null)) return;
|
||||
|
||||
try
|
||||
&& (self::$m_aTablesInfo[strtolower($sTableName)] != null))
|
||||
{
|
||||
// Check if the table exists
|
||||
$aFields = self::QueryToArray("SHOW COLUMNS FROM `$sTableName`");
|
||||
// Note: without backticks, you get an error with some table names (e.g. "group")
|
||||
foreach ($aFields as $aFieldData)
|
||||
{
|
||||
$sFieldName = $aFieldData["Field"];
|
||||
self::$m_aTablesInfo[strtolower($sTableName)]["Fields"][$sFieldName] =
|
||||
array
|
||||
(
|
||||
"Name"=>$aFieldData["Field"],
|
||||
"Type"=>$aFieldData["Type"],
|
||||
"Null"=>$aFieldData["Null"],
|
||||
"Key"=>$aFieldData["Key"],
|
||||
"Default"=>$aFieldData["Default"],
|
||||
"Extra"=>$aFieldData["Extra"]
|
||||
);
|
||||
}
|
||||
return;
|
||||
}
|
||||
catch(MySQLException $e)
|
||||
|
||||
// Create array entry, if table does not exist / has no columns
|
||||
self::$m_aTablesInfo[strtolower($sTableName)] = null;
|
||||
|
||||
// Get table informations
|
||||
// We were using SHOW COLUMNS FROM... but this don't return charset and collation info !
|
||||
// so since 2.5 and #1001 (switch to utf8mb4) we're using INFORMATION_SCHEMA !
|
||||
$aFields = self::QueryToArray('SELECT * FROM information_schema.`COLUMNS`'
|
||||
.' WHERE table_schema = "'.self::$m_sDBName.'" AND table_name = "'.$sTableName.'";');
|
||||
foreach ($aFields as $aFieldData)
|
||||
{
|
||||
// Table does not exist
|
||||
self::$m_aTablesInfo[strtolower($sTableName)] = null;
|
||||
$sFieldName = $aFieldData["COLUMN_NAME"];
|
||||
self::$m_aTablesInfo[strtolower($sTableName)]["Fields"][$sFieldName] =
|
||||
array
|
||||
(
|
||||
"Name" => $sFieldName,
|
||||
"Type" => $aFieldData["COLUMN_TYPE"],
|
||||
"Null" => $aFieldData["IS_NULLABLE"],
|
||||
"Key" => $aFieldData["COLUMN_KEY"],
|
||||
"Default" => $aFieldData["COLUMN_DEFAULT"],
|
||||
"Extra" => $aFieldData["EXTRA"],
|
||||
"Charset" => $aFieldData["CHARACTER_SET_NAME"],
|
||||
"Collation" => $aFieldData["COLLATION_NAME"],
|
||||
);
|
||||
}
|
||||
|
||||
if (!is_null(self::$m_aTablesInfo[strtolower($sTableName)]))
|
||||
@@ -1009,25 +1031,13 @@ class CMDBSource
|
||||
self::$m_aTablesInfo[strtolower($sTableName)]["Indexes"] = $aMyIndexes;
|
||||
}
|
||||
}
|
||||
//public static function EnumTables()
|
||||
//{
|
||||
// self::_TablesInfoCacheInit();
|
||||
// return array_keys(self::$m_aTablesInfo);
|
||||
//}
|
||||
|
||||
public static function GetTableInfo($sTable)
|
||||
{
|
||||
self::_TableInfoCacheInit($sTable);
|
||||
|
||||
// perform a case insensitive match because on Windows the table names become lowercase :-(
|
||||
//foreach(self::$m_aTablesInfo as $sTableName => $aInfo)
|
||||
//{
|
||||
// if (strtolower($sTableName) == strtolower($sTable))
|
||||
// {
|
||||
// return $aInfo;
|
||||
// }
|
||||
//}
|
||||
return self::$m_aTablesInfo[strtolower($sTable)];
|
||||
//return null;
|
||||
}
|
||||
|
||||
/**
|
||||
|
||||
@@ -4921,9 +4921,12 @@ abstract class MetaModel
|
||||
$aErrors = array();
|
||||
$aSugFix = array();
|
||||
|
||||
$sAlterDBMetaData = self::DBCheckCharsetAndCollation();
|
||||
|
||||
// A new way of representing things to be done - quicker to execute !
|
||||
$aCreateTable = array(); // array of <table> => <table options>
|
||||
$aCreateTableItems = array(); // array of <table> => array of <create definition>
|
||||
$aAlterTableMetaData = array();
|
||||
$aAlterTableItems = array(); // array of <table> => <alter specification>
|
||||
|
||||
foreach(self::GetClasses() as $sClass)
|
||||
@@ -4933,10 +4936,10 @@ abstract class MetaModel
|
||||
continue;
|
||||
}
|
||||
|
||||
|
||||
// Check that the table exists
|
||||
//
|
||||
$sTable = self::DBGetTable($sClass);
|
||||
$bTableToCreate = false;
|
||||
$sKeyField = self::DBGetKey($sClass);
|
||||
$sDbCharset = DEFAULT_CHARACTER_SET;
|
||||
$sDbCollation = DEFAULT_COLLATION;
|
||||
@@ -4944,6 +4947,7 @@ abstract class MetaModel
|
||||
$sKeyFieldDefinition = "`$sKeyField` INT(11) NOT NULL $sAutoIncrement PRIMARY KEY";
|
||||
if (!CMDBSource::IsTable($sTable))
|
||||
{
|
||||
$bTableToCreate = true;
|
||||
$aErrors[$sClass]['*'][] = "table '$sTable' could not be found in the DB";
|
||||
$aSugFix[$sClass]['*'][] = "CREATE TABLE `$sTable` ($sKeyFieldDefinition) ENGINE = ".MYSQL_ENGINE." CHARACTER SET $sDbCharset COLLATE $sDbCollation";
|
||||
$aCreateTable[$sTable] = "ENGINE = ".MYSQL_ENGINE." CHARACTER SET $sDbCharset COLLATE $sDbCollation";
|
||||
@@ -4955,7 +4959,7 @@ abstract class MetaModel
|
||||
{
|
||||
$aErrors[$sClass]['id'][] = "key '$sKeyField' (table $sTable) could not be found";
|
||||
$aSugFix[$sClass]['id'][] = "ALTER TABLE `$sTable` ADD $sKeyFieldDefinition";
|
||||
if (!array_key_exists($sTable, $aCreateTable))
|
||||
if (!$bTableToCreate)
|
||||
{
|
||||
$aAlterTableItems[$sTable][$sKeyField] = "ADD $sKeyFieldDefinition";
|
||||
}
|
||||
@@ -4968,7 +4972,7 @@ abstract class MetaModel
|
||||
{
|
||||
$aErrors[$sClass]['id'][] = "key '$sKeyField' is not a key for table '$sTable'";
|
||||
$aSugFix[$sClass]['id'][] = "ALTER TABLE `$sTable`, DROP PRIMARY KEY, ADD PRIMARY key(`$sKeyField`)";
|
||||
if (!array_key_exists($sTable, $aCreateTable))
|
||||
if (!$bTableToCreate)
|
||||
{
|
||||
$aAlterTableItems[$sTable][$sKeyField] = "CHANGE `$sKeyField` $sKeyFieldDefinition";
|
||||
}
|
||||
@@ -4977,13 +4981,22 @@ abstract class MetaModel
|
||||
{
|
||||
$aErrors[$sClass]['id'][] = "key '$sKeyField' (table $sTable) is not automatically incremented";
|
||||
$aSugFix[$sClass]['id'][] = "ALTER TABLE `$sTable` CHANGE `$sKeyField` $sKeyFieldDefinition";
|
||||
if (!array_key_exists($sTable, $aCreateTable))
|
||||
if (!$bTableToCreate)
|
||||
{
|
||||
$aAlterTableItems[$sTable][$sKeyField] = "CHANGE `$sKeyField` $sKeyFieldDefinition";
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
if (!$bTableToCreate)
|
||||
{
|
||||
$sAlterTableMetaDataQuery = self::DBCheckTableCharsetAndCollation($sTable);
|
||||
if (!empty($sAlterTableMetaDataQuery))
|
||||
{
|
||||
$aAlterTableMetaData[$sTable] = $sAlterTableMetaDataQuery;
|
||||
}
|
||||
}
|
||||
|
||||
// Check that any defined field exists
|
||||
//
|
||||
$aTableInfo = CMDBSource::GetTableInfo($sTable);
|
||||
@@ -5014,7 +5027,7 @@ abstract class MetaModel
|
||||
{
|
||||
$aSugFix[$sClass][$sAttCode][] = "ALTER TABLE `$sTable` ADD INDEX (`$sField`)";
|
||||
}
|
||||
if (array_key_exists($sTable, $aCreateTable))
|
||||
if ($bTableToCreate)
|
||||
{
|
||||
$aCreateTableItems[$sTable][$sField] = $sFieldDefinition;
|
||||
if ($bIndexNeeded)
|
||||
@@ -5087,7 +5100,7 @@ abstract class MetaModel
|
||||
$aErrors[$sClass]['*'][] = "Missing index '$sIndexId' ($sColumns) in table '$sTable'";
|
||||
$aSugFix[$sClass]['*'][] = "ALTER TABLE `$sTable` ADD INDEX `$sIndexId` ($sColumns)";
|
||||
}
|
||||
if (array_key_exists($sTable, $aCreateTable))
|
||||
if ($bTableToCreate)
|
||||
{
|
||||
$aCreateTableItems[$sTable][] = "INDEX `$sIndexId` ($sColumns)";
|
||||
}
|
||||
@@ -5122,12 +5135,20 @@ abstract class MetaModel
|
||||
}
|
||||
|
||||
$aCondensedQueries = array();
|
||||
if (!empty($sAlterDBMetaData))
|
||||
{
|
||||
$aCondensedQueries[] = $sAlterDBMetaData;
|
||||
}
|
||||
foreach($aCreateTable as $sTable => $sTableOptions)
|
||||
{
|
||||
$sTableItems = implode(', ', $aCreateTableItems[$sTable]);
|
||||
$aCondensedQueries[] = "CREATE TABLE `$sTable` ($sTableItems) $sTableOptions";
|
||||
}
|
||||
foreach($aAlterTableItems as $sTable => $aChangeList)
|
||||
foreach ($aAlterTableMetaData as $sTableAlterQuery)
|
||||
{
|
||||
$aCondensedQueries[] = $sTableAlterQuery;
|
||||
}
|
||||
foreach ($aAlterTableItems as $sTable => $aChangeList)
|
||||
{
|
||||
$sChangeList = implode(', ', $aChangeList);
|
||||
$aCondensedQueries[] = "ALTER TABLE `$sTable` $sChangeList";
|
||||
@@ -5136,6 +5157,59 @@ abstract class MetaModel
|
||||
return array($aErrors, $aSugFix, $aCondensedQueries);
|
||||
}
|
||||
|
||||
/**
|
||||
* @return string query to upgrade database charset and collation if needed, null if not
|
||||
* @throws \MySQLException
|
||||
*
|
||||
* @since 2.5 #1001 switch to utf8mb4
|
||||
* @see https://dev.mysql.com/doc/refman/5.7/en/charset-database.html
|
||||
*/
|
||||
private static function DBCheckCharsetAndCollation()
|
||||
{
|
||||
$sDBName = CMDBSource::DBName();
|
||||
$sDBInfoQuery = "SELECT DEFAULT_CHARACTER_SET_NAME, DEFAULT_COLLATION_NAME
|
||||
FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME = '$sDBName';";
|
||||
$aDBInfo = CMDBSource::QueryToArray($sDBInfoQuery);
|
||||
$sDBCharset = $aDBInfo[0]['DEFAULT_CHARACTER_SET_NAME'];
|
||||
$sDBCollation = $aDBInfo[0]['DEFAULT_COLLATION_NAME'];
|
||||
|
||||
if ((DEFAULT_CHARACTER_SET == $sDBCharset) && (DEFAULT_COLLATION == $sDBCollation))
|
||||
{
|
||||
return null;
|
||||
}
|
||||
|
||||
return 'ALTER DATABASE'.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION.';';
|
||||
}
|
||||
|
||||
/**
|
||||
* @param string $sTableName
|
||||
*
|
||||
* @return string query to upgrade table charset and collation if needed, null if not
|
||||
* @throws \MySQLException
|
||||
*
|
||||
* @since 2.5 #1001 switch to utf8mb4
|
||||
* @see https://dev.mysql.com/doc/refman/5.7/en/charset-table.html
|
||||
*/
|
||||
private static function DBCheckTableCharsetAndCollation($sTableName)
|
||||
{
|
||||
$sDBName = CMDBSource::DBName();
|
||||
$sTableInfoQuery = "SELECT C.character_set_name, T.table_collation
|
||||
FROM information_schema.`TABLES` T inner join information_schema.`COLLATION_CHARACTER_SET_APPLICABILITY` C
|
||||
ON T.table_collation = C.collation_name
|
||||
WHERE T.table_schema = '$sDBName'
|
||||
AND T.table_name = '$sTableName';";
|
||||
$aTableInfo = CMDBSource::QueryToArray($sTableInfoQuery);
|
||||
$sTableCharset = $aTableInfo[0]['character_set_name'];
|
||||
$sTableCollation = $aTableInfo[0]['table_collation'];
|
||||
|
||||
if ((DEFAULT_CHARACTER_SET == $sTableCharset) && (DEFAULT_COLLATION == $sTableCollation))
|
||||
{
|
||||
return null;
|
||||
}
|
||||
|
||||
return 'ALTER TABLE `'.$sTableName.'`'.CMDBSource::SQL_STRING_COLUMNS_CHARSET_DEFINITION.';';
|
||||
}
|
||||
|
||||
/**
|
||||
* @return array
|
||||
* @throws \CoreException
|
||||
|
||||
Reference in New Issue
Block a user