1
0
mirror of https://github.com/e107inc/e107.git synced 2025-07-25 00:41:52 +02:00

Merge pull request #4508 from Deltik/fix/4501

Issue #4501 Migrate database charset to utf8mb4 and storage engine to InnoDB
This commit is contained in:
Cameron
2023-11-28 15:24:42 -08:00
committed by GitHub
12 changed files with 469 additions and 133 deletions

View File

@@ -491,7 +491,7 @@ class system_tools
if(vartrue($_POST['createdb']))
{
if($sql->gen("CREATE DATABASE ".$database." CHARACTER SET `utf8`"))
if($sql->gen("CREATE DATABASE ".$database." CHARACTER SET `utf8mb4`"))
{
$mes->addSuccess(DBLAN_75);
@@ -556,7 +556,7 @@ class system_tools
preg_match_all("/create(.*?)(?:myisam|innodb);/si", $sql_data, $result );
$sql->gen('SET NAMES `utf8`');
$sql->gen('SET NAMES `utf8mb4`');
foreach ($result[0] as $sql_table)
{
@@ -769,11 +769,11 @@ class system_tools
<td>".$row['Name']."</td>
<td>".$row['Engine']."</td>
<td>".$row['Collation']."</td>
<td>".(($row['Collation'] == 'utf8_general_ci') ? defset('ADMIN_TRUE_ICON') : defset('ADMIN_FALSE_ICON'))."</td>
<td>".(($row['Collation'] == 'utf8mb4_general_ci') ? defset('ADMIN_TRUE_ICON') : defset('ADMIN_FALSE_ICON'))."</td>
</tr>";
// print_a($row);
if($row['Collation'] != 'utf8_general_ci')
if($row['Collation'] != 'utf8mb4_general_ci')
{
$invalidCollations = true;
}
@@ -842,12 +842,12 @@ class system_tools
$queries = array();
$queries[] = $this->getQueries("SELECT CONCAT('ALTER TABLE `', table_name, '` MODIFY ', column_name, ' ', REPLACE(column_type, 'char', 'binary'), ';') FROM information_schema.columns WHERE TABLE_SCHEMA = '".$dbtable."' AND TABLE_NAME LIKE '".$config['mySQLprefix']."%' AND COLLATION_NAME != 'utf8_general_ci' and data_type LIKE '%char%';");
$queries[] = $this->getQueries("SELECT CONCAT('ALTER TABLE `', table_name, '` MODIFY ', column_name, ' ', REPLACE(column_type, 'text', 'blob'), ';') FROM information_schema.columns WHERE TABLE_SCHEMA = '".$dbtable."' AND TABLE_NAME LIKE '".$config['mySQLprefix']."%' AND COLLATION_NAME != 'utf8_general_ci' and data_type LIKE '%text%';");
$queries[] = $this->getQueries("SELECT CONCAT('ALTER TABLE `', table_name, '` MODIFY ', column_name, ' ', REPLACE(column_type, 'char', 'binary'), ';') FROM information_schema.columns WHERE TABLE_SCHEMA = '".$dbtable."' AND TABLE_NAME LIKE '".$config['mySQLprefix']."%' AND COLLATION_NAME != 'utf8mb4_general_ci' and data_type LIKE '%char%';");
$queries[] = $this->getQueries("SELECT CONCAT('ALTER TABLE `', table_name, '` MODIFY ', column_name, ' ', REPLACE(column_type, 'text', 'blob'), ';') FROM information_schema.columns WHERE TABLE_SCHEMA = '".$dbtable."' AND TABLE_NAME LIKE '".$config['mySQLprefix']."%' AND COLLATION_NAME != 'utf8mb4_general_ci' and data_type LIKE '%text%';");
$queries2 = array();
$queries2[] = $this->getQueries("SELECT CONCAT('ALTER TABLE `', table_name, '` MODIFY ', column_name, ' ', column_type, ' CHARACTER SET utf8;') FROM information_schema.columns WHERE TABLE_SCHEMA ='".$dbtable."' AND TABLE_NAME LIKE '".$config['mySQLprefix']."%' AND COLLATION_NAME != 'utf8_general_ci' and data_type LIKE '%char%';");
$queries2[] = $this->getQueries("SELECT CONCAT('ALTER TABLE `', table_name, '` MODIFY ', column_name, ' ', column_type, ' CHARACTER SET utf8;') FROM information_schema.columns WHERE TABLE_SCHEMA = '".$dbtable."' AND TABLE_NAME LIKE '".$config['mySQLprefix']."%' AND COLLATION_NAME != 'utf8_general_ci' and data_type LIKE '%text%';");
$queries2[] = $this->getQueries("SELECT CONCAT('ALTER TABLE `', table_name, '` MODIFY ', column_name, ' ', column_type, ' CHARACTER SET utf8mb4;') FROM information_schema.columns WHERE TABLE_SCHEMA ='".$dbtable."' AND TABLE_NAME LIKE '".$config['mySQLprefix']."%' AND COLLATION_NAME != 'utf8mb4_general_ci' and data_type LIKE '%char%';");
$queries2[] = $this->getQueries("SELECT CONCAT('ALTER TABLE `', table_name, '` MODIFY ', column_name, ' ', column_type, ' CHARACTER SET utf8mb4;') FROM information_schema.columns WHERE TABLE_SCHEMA = '".$dbtable."' AND TABLE_NAME LIKE '".$config['mySQLprefix']."%' AND COLLATION_NAME != 'utf8mb4_general_ci' and data_type LIKE '%text%';");
// $sql->gen("USE ".$dbtable);
@@ -881,7 +881,7 @@ class system_tools
// Convert Table Fields to utf8
$sql2 = e107::getDb('sql2');
$sql->gen('SHOW TABLE STATUS WHERE Collation != "utf8_general_ci" ');
$sql->gen('SHOW TABLE STATUS WHERE Collation != "utf8mb4_general_ci" ');
while ($row = $sql->fetch())
{
$table = $row['Name'];
@@ -892,7 +892,7 @@ class system_tools
}
$tab_query = "ALTER TABLE ".$table." DEFAULT CHARACTER SET utf8 COLLATE utf8_general_ci; ";
$tab_query = "ALTER TABLE ".$table." DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci; ";
//echo "TABQRT= ".$tab_query;
@@ -927,7 +927,7 @@ class system_tools
//------------
$lastQry = "ALTER DATABASE `".$dbtable."` DEFAULT CHARACTER SET utf8 COLLATE utf8_general_ci;";
$lastQry = "ALTER DATABASE `".$dbtable."` DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci;";
if(!$sql->db_Query($lastQry))
{
@@ -936,11 +936,10 @@ class system_tools
elseif($ERROR != TRUE)
{
$message = DBLAN_93;
//$message .= "<br />Please now add the following line to your e107_config.php file:<br /><b>\$mySQLcharset = 'utf8';</b>";
$mes->add($message, E_MESSAGE_SUCCESS);
$mes->addSuccess(DBLAN_94);
$mes->addSuccess('$mySQLcharset = "utf8";');
$mes->addSuccess('$mySQLcharset = "utf8mb4";');
}

View File

@@ -1,14 +1,13 @@
<?php
/*
/**
* e107 website system
*
* Copyright (C) e107 Inc (e107.org)
* Copyright (C) 2008-2021 e107 Inc (e107.org)
* Released under the terms and conditions of the
* GNU General Public License (http://www.gnu.org/licenses/gpl.txt)
*
* Core SQL
*
*/
*/
header("location:../index.php");
exit;
@@ -17,7 +16,7 @@ exit;
# +---------------------------------------------------------------+
# | e107 website system
# |
# | Copyright (C) 2008-2015 e107 Inc (e107.org)
# | Copyright (C) 2008-2021 e107 Inc (e107.org)
# | http://e107.org
# |
# | Released under the terms and conditions of the
@@ -41,7 +40,7 @@ CREATE TABLE admin_log (
dblog_remarks text NOT NULL,
PRIMARY KEY (dblog_id),
KEY dblog_datestamp (dblog_datestamp)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -59,7 +58,7 @@ CREATE TABLE audit_log (
dblog_remarks text NOT NULL,
PRIMARY KEY (dblog_id),
KEY dblog_datestamp (dblog_datestamp)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
@@ -80,7 +79,7 @@ CREATE TABLE banlist (
KEY banlist_ip (banlist_ip),
KEY banlist_datestamp (banlist_datestamp),
KEY banlist_banexpires (banlist_banexpires)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -105,7 +104,7 @@ CREATE TABLE comments (
PRIMARY KEY (comment_id),
KEY comment_blocked (comment_blocked),
KEY comment_author_id (comment_author_id)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -115,7 +114,7 @@ CREATE TABLE core (
e107_name varchar(100) NOT NULL default '',
e107_value text NOT NULL,
PRIMARY KEY (e107_name)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -139,7 +138,7 @@ CREATE TABLE core_media (
media_tags text NOT NULL,
PRIMARY KEY (media_id),
UNIQUE KEY media_url (media_url)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
CREATE TABLE core_media_cat (
media_cat_id int(10) unsigned NOT NULL auto_increment,
@@ -153,7 +152,7 @@ CREATE TABLE core_media_cat (
media_cat_order int(3) unsigned NOT NULL default '0',
PRIMARY KEY (media_cat_id),
UNIQUE KEY media_cat_category (media_cat_category)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
CREATE TABLE cron (
@@ -187,7 +186,7 @@ CREATE TABLE dblog (
dblog_remarks text NOT NULL,
PRIMARY KEY (dblog_id),
KEY dblog_datestamp (dblog_datestamp)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
@@ -204,7 +203,7 @@ CREATE TABLE generic (
gen_chardata text NOT NULL,
PRIMARY KEY (gen_id),
KEY gen_type (gen_type)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -227,7 +226,7 @@ CREATE TABLE links (
link_sefurl varchar(255) NOT NULL,
link_owner varchar(50) NOT NULL default '',
PRIMARY KEY (link_id)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
@@ -248,7 +247,7 @@ CREATE TABLE mail_recipients (
PRIMARY KEY (mail_target_id),
KEY mail_status (mail_status),
KEY mail_detail_id (mail_detail_id)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
CREATE TABLE mail_content (
mail_source_id int(10) unsigned NOT NULL auto_increment,
@@ -274,7 +273,7 @@ CREATE TABLE mail_content (
mail_media text,
PRIMARY KEY (mail_source_id),
KEY mail_content_status (mail_content_status)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
#
@@ -292,7 +291,7 @@ CREATE TABLE menus (
menu_layout varchar(100) NOT NULL default '',
menu_parms text NOT NULL,
PRIMARY KEY (menu_id)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -330,7 +329,7 @@ CREATE TABLE news (
KEY news_sticky (news_sticky),
KEY news_render_type (news_render_type),
KEY news_class (news_class)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
@@ -351,7 +350,7 @@ CREATE TABLE news_category (
category_template varchar(50) default NULL,
PRIMARY KEY (category_id),
KEY category_order (category_order)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -411,7 +410,7 @@ CREATE TABLE page (
menu_button_text varchar(250) NOT NULL default '',
PRIMARY KEY (page_id)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
@@ -435,7 +434,7 @@ CREATE TABLE page_chapters (
chapter_fields mediumtext,
PRIMARY KEY (chapter_id),
KEY chapter_order (chapter_order)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
@@ -454,7 +453,7 @@ CREATE TABLE plugin (
plugin_category varchar(100) NOT NULL default '',
PRIMARY KEY (plugin_id),
UNIQUE KEY plugin_path (plugin_path)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -471,7 +470,7 @@ CREATE TABLE rate (
rate_up int(10) unsigned NOT NULL default '0',
rate_down int(10) unsigned NOT NULL default '0',
PRIMARY KEY (rate_id)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -485,7 +484,7 @@ CREATE TABLE session (
session_data longtext NOT NULL,
PRIMARY KEY (session_id),
INDEX (session_expires)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
@@ -510,7 +509,7 @@ CREATE TABLE submitnews (
submitnews_summary text,
submitnews_media text,
PRIMARY KEY (submitnews_id)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -523,7 +522,7 @@ CREATE TABLE tmp (
tmp_info text NOT NULL,
KEY tmp_ip (tmp_ip),
KEY tmp_time (tmp_time)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -548,7 +547,7 @@ CREATE TABLE upload (
upload_owner varchar(50) NOT NULL default '',
PRIMARY KEY (upload_id),
KEY upload_active (upload_active)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
@@ -588,7 +587,7 @@ CREATE TABLE user (
UNIQUE KEY user_name (user_name),
UNIQUE KEY user_loginname (user_loginname),
KEY join_ban_index (user_join,user_ban)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -606,7 +605,7 @@ CREATE TABLE userclass_classes (
userclass_icon varchar(250) NOT NULL default '',
userclass_perms text NOT NULL,
PRIMARY KEY (userclass_id)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
#
@@ -617,7 +616,7 @@ CREATE TABLE user_extended (
user_extended_id int(10) unsigned NOT NULL default '0',
user_hidden_fields text,
PRIMARY KEY (user_extended_id)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------
@@ -641,6 +640,6 @@ CREATE TABLE user_extended_struct (
user_extended_struct_order int(10) unsigned NOT NULL default '0',
user_extended_struct_parent int(10) unsigned NOT NULL default '0',
PRIMARY KEY (user_extended_struct_id)
) ENGINE=MyISAM;
) ENGINE=InnoDB;
# --------------------------------------------------------

View File

@@ -27,7 +27,9 @@ class db_verify
{
var $backUrl = "";
public $sqlFileTables = array();
private $sqlDatabaseTables = array();
const MOST_PREFERRED_STORAGE_ENGINE = "InnoDB";
const MOST_PREFERRED_CHARSET = "utf8mb4";
public $availableStorageEngines = array(self::MOST_PREFERRED_STORAGE_ENGINE);
var $sqlLanguageTables = array();
var $results = array();
@@ -35,13 +37,29 @@ class db_verify
var $fixList = array();
private $currentTable = null;
private $internalError = false;
/**
* Aliases for preferred storage engines when provided the key
* @var string[][]
*/
private $storageEnginePreferenceMap = [
"MyISAM" => [self::MOST_PREFERRED_STORAGE_ENGINE, "Aria", "Maria", "MyISAM"],
"Aria" => ["Aria", "Maria", "MyISAM"],
"InnoDB" => ["InnoDB", "XtraDB"],
"XtraDB" => ["XtraDB", "InnoDB"],
];
var $fieldTypes = array('time','timestamp','datetime','year','tinyblob','blob',
'mediumblob','longblob','tinytext','mediumtext','longtext','text','date', 'json');
var $fieldTypeNum = array('bit','tinyint','smallint','mediumint','integer','int','bigint',
'real','double','float','decimal','numeric','varchar','char ','binary','varbinary','enum','set'); // space after 'char' required.
'real','double','float','decimal','numeric','varchar','char','binary','varbinary','enum','set');
const STATUS_TABLE_OK = 0x0;
const STATUS_TABLE_MISSING = 0x1 << 1;
const STATUS_TABLE_MISMATCH_STORAGE_ENGINE = 0x1 << 2;
const STATUS_TABLE_MISMATCH_DEFAULT_CHARSET = 0x1 << 3;
var $modes = array(
'missing_table' => 'create',
'mismatch' => 'alter',
@@ -66,14 +84,20 @@ class db_verify
if(!deftrue('e_DEBUG') && $tmp = e107::getCache()->retrieve(self::cachetag, 15, true, true))
{
$this->sqlFileTables = e107::unserialize($tmp);
$cacheData = e107::unserialize($tmp);
$this->sqlFileTables = isset($cacheData['sqlFileTables']) ? $cacheData['sqlFileTables'] : $this->load();
$this->availableStorageEngines = isset($cacheData['availableStorageEngines']) ?
$cacheData['availableStorageEngines'] : $this->getAvailableStorageEngines();
}
else
{
$this->sqlFileTables = $this->load();
$data = e107::serialize($this->sqlFileTables,'json');
e107::getCache()->set(self::cachetag,$data, true, true, true);
$this->availableStorageEngines = $this->getAvailableStorageEngines();
$cacheData = e107::serialize([
'sqlFileTables' => $this->sqlFileTables,
'availableStorageEngines' => $this->availableStorageEngines,
], 'json');
e107::getCache()->set(self::cachetag, $cacheData, true, true, true);
}
@@ -143,7 +167,7 @@ class db_verify
$expected['default'] = isset($expected['default']) ? $expected['default'] : '';
$actual['default'] = isset($actual['default']) ? $actual['default'] : '';
if($expected['type'] === 'JSON') // Fix for JSON alias MySQL 5.7+
if($expected['type'] === 'JSON' && $actual['type'] !== 'JSON') // Fix for JSON alias MySQL 5.7+
{
$expected['type'] = 'LONGTEXT';
}
@@ -223,7 +247,7 @@ class db_verify
}
}
if($cnt = count($this->errors))
if($cnt = $this->errors())
{
$message = str_replace("[x]",$cnt,DBVLAN_26); // Found [x] issues.
$mes->add($message, E_MESSAGE_WARNING);
@@ -320,8 +344,6 @@ class db_verify
foreach($this->sqlFileTables[$selection]['tables'] as $key=>$tbl)
{
//$this->errors[$tbl]['_status'] = 'ok'; // default table status
$rawSqlData = $this->getSqlData($tbl,$language);
@@ -332,8 +354,9 @@ class db_verify
$this->errors[$tbl]['_status'] = 'missing_table';
$this->results[$tbl]['_file'] = $selection;
$this->errors[$tbl]['_status'] = self::STATUS_TABLE_MISSING;
$this->errors[$tbl]['_file'] = $selection;
$this->results[$tbl] = [];
// echo "missing table: $tbl";
continue;
}
@@ -353,6 +376,13 @@ class db_verify
$fileData['index'] = $this->getIndex($this->sqlFileTables[$selection]['data'][$key]);
$sqlData['index'] = $this->getIndex($sqlDataArr['data'][0]);
$maybeEngine = isset($sqlDataArr['engine'][0]) ? $sqlDataArr['engine'][0] : 'INTERNAL_ERROR:ENGINE';
$fileData['engine'] = $this->getIntendedStorageEngine($this->sqlFileTables[$selection]['engine'][$key]);
$sqlData['engine'] = $this->getCanonicalStorageEngine($maybeEngine);
$maybeCharset = isset($sqlDataArr['charset'][0]) ? $sqlDataArr['charset'][0] : 'INTERNAL_ERROR:CHARSET';
$fileData['charset'] = $this->getIntendedCharset($this->sqlFileTables[$selection]['charset'][$key]);
$sqlData['charset'] = $this->getCanonicalCharset($maybeCharset);
/*
$debugA = print_r($fileFieldData,TRUE); // Extracted Field Arrays
@@ -433,20 +463,22 @@ class db_verify
$results = 'indices';
}
if (!isset($this->errors[$tbl])) $this->errors[$tbl] = [];
if (!isset($this->errors[$tbl]['_status'])) $this->errors[$tbl]['_status'] = self::STATUS_TABLE_OK;
$this->errors[$tbl]['_file'] = $selection;
foreach($fileData[$type] as $key => $value)
{
$this->{$results}[$tbl][$key]['_status'] = 'ok';
if(!isset($sqlData[$type][$key]) || !is_array($sqlData[$type][$key]))
{
$this->errors[$tbl]['_status'] = 'error'; // table status
$this->{$results}[$tbl][$key]['_status'] = "missing_$type"; // type status
$this->{$results}[$tbl][$key]['_valid'] = $value;
$this->{$results}[$tbl][$key]['_file'] = $selection;
}
elseif(count($diff = $this->diffStructurePermissive($value, $sqlData[$type][$key])))
{
$this->errors[$tbl]['_status'] = "mismatch_$type";
$this->{$results}[$tbl][$key]['_status'] = 'mismatch';
$this->{$results}[$tbl][$key]['_diff'] = $diff;
$this->{$results}[$tbl][$key]['_valid'] = $value;
@@ -457,6 +489,19 @@ class db_verify
}
if ($fileData['engine'] != $sqlData['engine'])
{
$this->errors[$tbl]['_status'] |= self::STATUS_TABLE_MISMATCH_STORAGE_ENGINE;
$this->errors[$tbl]['_valid_' . self::STATUS_TABLE_MISMATCH_STORAGE_ENGINE] = $fileData['engine'];
$this->errors[$tbl]['_invalid_' . self::STATUS_TABLE_MISMATCH_STORAGE_ENGINE] = $sqlData['engine'];
}
if ($fileData['charset'] != $sqlData['charset'])
{
$this->errors[$tbl]['_status'] |= self::STATUS_TABLE_MISMATCH_DEFAULT_CHARSET;
$this->errors[$tbl]['_valid_' . self::STATUS_TABLE_MISMATCH_DEFAULT_CHARSET] = $fileData['charset'];
$this->errors[$tbl]['_invalid_' . self::STATUS_TABLE_MISMATCH_DEFAULT_CHARSET] = $sqlData['charset'];
}
}
return null;
@@ -476,23 +521,28 @@ class db_verify
foreach($this->results as $tabs => $field)
{
$file = varset($this->results[$tabs]['_file']);
$errorStatus = !empty($this->errors[$tabs]['_status']) ? $this->errors[$tabs]['_status'] : null;
$errorStatus = is_int($this->errors[$tabs]['_status']) ?
$this->errors[$tabs]['_status'] : self::STATUS_TABLE_OK;
if($errorStatus === 'missing_table') // Missing Table
if($errorStatus & self::STATUS_TABLE_MISSING) // Missing Table
{
$this->fixList[$file][$tabs]['all'][] = 'create';
}
elseif($this->errors[$tabs] != 'ok') // All Other Issues..
}
elseif (
$errorStatus & self::STATUS_TABLE_MISMATCH_STORAGE_ENGINE ||
$errorStatus & self::STATUS_TABLE_MISMATCH_DEFAULT_CHARSET
)
{
foreach($field as $k=>$f)
$this->fixList[$file][$tabs]['all'][] = 'convert';
}
foreach($field as $k=>$f)
{
if($f['_status']=='ok') continue;
$status = $f['_status'];
if(!empty($this->modes[$status]))
{
if($f['_status']=='ok') continue;
$status = $f['_status'];
if(!empty($this->modes[$status]))
{
$this->fixList[$f['_file']][$tabs][$k][] = $this->modes[$status];
}
}
$this->fixList[$f['_file']][$tabs][$k][] = $this->modes[$status];
}
}
}
@@ -520,7 +570,33 @@ class db_verify
*/
public function errors()
{
return count($this->errors);
$badTableCount = 0;
foreach ($this->errors as $tableName => $tableMetadata)
{
if (!empty($tableMetadata['_status']))
{
$badTableCount++;
continue;
}
foreach ($this->results[$tableName] as $fieldMetadata)
{
if (isset($fieldMetadata['_status']) && $fieldMetadata['_status'] != 'ok')
{
$badTableCount++;
continue 2;
}
}
foreach ($this->indices[$tableName] as $indexMetadata)
{
if (isset($indexMetadata['_status']) && $indexMetadata['_status'] != 'ok')
{
$badTableCount++;
continue 2;
}
}
}
return $badTableCount;
}
@@ -559,40 +635,60 @@ class db_verify
</thead>
<tbody>
";
$info = array(
'missing_table' => DBVLAN_13,
'mismatch' => DBVLAN_8,
'missing_field' => DBVLAN_11,
'ok' => ADMIN_TRUE_ICON,
'missing_index' => DBVLAN_25,
self::STATUS_TABLE_MISSING => DBVLAN_13,
self::STATUS_TABLE_MISMATCH_STORAGE_ENGINE => DBVLAN_17,
self::STATUS_TABLE_MISMATCH_DEFAULT_CHARSET => DBVLAN_18,
'mismatch' => DBVLAN_8,
'missing_field' => DBVLAN_11,
'ok' => ADMIN_TRUE_ICON,
'missing_index' => DBVLAN_25,
);
foreach($this->results as $tabs => $field)
{
if($this->errors[$tabs]['_status'] === 'missing_table') // Missing Table
$tableStatus = $this->errors[$tabs]['_status'];
if($tableStatus != self::STATUS_TABLE_OK) // Missing Table
{
$errors = [];
$parser = e107::getParser();
foreach ([
self::STATUS_TABLE_MISSING,
self::STATUS_TABLE_MISMATCH_STORAGE_ENGINE,
self::STATUS_TABLE_MISMATCH_DEFAULT_CHARSET
] as $statusFlag)
{
if ($tableStatus & $statusFlag)
$errors[] = $parser->lanVars(
$info[$statusFlag],
[
'x' => $this->errors[$tabs]['_valid_' . $statusFlag],
'y' => $this->errors[$tabs]['_invalid_' . $statusFlag],
]
);
}
$fixMode = $tableStatus & self::STATUS_TABLE_MISSING ? 'create' : 'convert';
$text .= "
<tr>
<td>".$this->renderTableName($tabs)."</td>
<td>&nbsp;</td>
<td class='center middle error'>".$info[$this->errors[$tabs]['_status']]."</td>
<td>&nbsp;</td>
<td class='center middle autocheck e-pointer'>".$this->fixForm($this->results[$tabs]['_file'],$tabs, 'all', '', 'create') . "</td>
<td><em>".DBVLAN_28."</em></td>
<td class='center middle error'>".DBVLAN_27."</td>
<td>".implode("<br />", $errors)."</td>
<td class='center middle autocheck e-pointer'>".$this->fixForm($this->errors[$tabs]['_file'],$tabs, 'all', '', $fixMode) . "</td>
</tr>
";
}
elseif($this->errors[$tabs] != 'ok') // All Other Issues..
}
foreach($field as $k=>$f)
{
foreach($field as $k=>$f)
{
if($f['_status']=='ok') continue;
$fstat = $info[$f['_status']];
$text .= "
if($f['_status']=='ok') continue;
$fstat = $info[$f['_status']];
$text .= "
<tr>
<td>".$this->renderTableName($tabs)."</td>
<td>".$k."&nbsp;</td>
@@ -600,10 +696,8 @@ class db_verify
<td>".$this->renderNotes($f)."&nbsp;</td>
<td class='center middle autocheck e-pointer'>".$this->fixForm($f['_file'],$tabs, $k, $f['_valid'], $this->modes[$f['_status']]) . "</td>
</tr>
";
}
";
}
}
@@ -814,9 +908,17 @@ class db_verify
* @param string $field eg. submitnews_id
* @param string $sqlFileData (after CREATE) eg. dblog_id int(10) unsigned NOT NULL auto_increment, ..... KEY....
* @param string $engine MyISAM|InnoDB
* @param string $charset MySQL/MariaDB text character set
* @return string SQL query
*/
function getFixQuery($mode, $table, $field, $sqlFileData, $engine = 'MyISAM' )
function getFixQuery(
$mode,
$table,
$field,
$sqlFileData,
$engine = self::MOST_PREFERRED_STORAGE_ENGINE,
$charset = self::MOST_PREFERRED_CHARSET
)
{
if(strpos($mode, 'index') === 0)
@@ -830,6 +932,7 @@ class db_verify
$newval = $this->toMysql($fdata[$field]);
}
$query = "";
switch($mode)
{
@@ -856,8 +959,18 @@ class db_verify
break;
case 'create':
$query = "CREATE TABLE `".MPREFIX.$table."` (".$sqlFileData.") ENGINE=".$engine.";";
$query = "CREATE TABLE `".MPREFIX.$table."` (".$sqlFileData.")".
" ENGINE=".$engine." DEFAULT CHARACTER SET=".$charset.";";
break;
case 'convert':
$showCreateTable = $this->getSqlData($table);
$currentSchema = $this->getSqlFileTables($showCreateTable);
if ($engine != $currentSchema['engine'][0])
$query .= "ALTER TABLE `".MPREFIX.$table."` ENGINE=".$engine.";";
if ($charset != $currentSchema['charset'][0])
$query .= "ALTER TABLE `".MPREFIX.$table."` CONVERT TO CHARACTER SET ".$charset.";";
break;
}
@@ -895,7 +1008,14 @@ class db_verify
foreach($fixes as $mode)
{
$query = $this->getFixQuery($mode,$table,$field,$this->sqlFileTables[$j]['data'][$id],$this->sqlFileTables[$j]['engine'][$id]);
$query = $this->getFixQuery(
$mode,
$table,
$field,
$this->sqlFileTables[$j]['data'][$id],
$this->getIntendedStorageEngine($this->sqlFileTables[$j]['engine'][$id]),
$this->getIntendedCharset($this->sqlFileTables[$j]['charset'][$id])
);
// $mes->addDebug("Query: ".$query);
@@ -948,14 +1068,8 @@ class db_verify
$ret = array();
$sql_data = preg_replace("#\/\*.*?\*\/#mis", '', $sql_data); // remove comments
// echo "<h4>SqlData</h4>";
// print_a($sql_data);
// $regex = "/CREATE TABLE `?([\w]*)`?\s*?\(([\s\w\+\-_\(\),'\. `]*)\)\s*(ENGINE|TYPE)\s*?=\s?([\w]*)[\w =]*;/i";
// $regex = "/CREATE TABLE (?:IF NOT EXISTS )?`?([\w]*)`?\s*?\(([\s\w\+\-_\(\),:'\. `]*)\)\s*(ENGINE|TYPE)\s*?=\s?([\w]*)[\w =]*;/i";
// also support non-alphanumeric chars.
$regex = "/CREATE TABLE (?:IF NOT EXISTS )?`?([\w]*)`?\s*?\(([^;]*)\)\s*(ENGINE|TYPE)\s*?=\s?([\w]*)[\w =]*;/i";
$regex = "/CREATE TABLE (?:IF NOT EXISTS )?`?([\w]*)`?\s*?\(([^;]*)\)\s*((?:[\w\s]+=[^\s]+)+\s*)*;/i";
preg_match_all($regex,$sql_data,$match);
@@ -986,8 +1100,44 @@ class db_verify
}
$ret['data'] = $data;
$ret['engine'] = $match[4];
$ret['engine'] = array();
$ret['charset'] = array();
foreach ($match[3] as $rawTableOptions)
{
if (empty($rawTableOptions)) continue;
$engine = null;
$charset = null;
$tableOptionsRegex = "/([\w\s]+=[\w]+)+?\s*/";
preg_match_all($tableOptionsRegex, $rawTableOptions, $tableOptionsSplit);
$tableOptionsSplit = current($tableOptionsSplit);
foreach ($tableOptionsSplit as $rawTableOption)
{
list($tableOptionName, $tableOptionValue) = explode("=", $rawTableOption, 2);
$tableOptionName = strtoupper(trim($tableOptionName));
$tableOptionValue = trim($tableOptionValue);
switch ($tableOptionName)
{
case "ENGINE":
case "TYPE":
$engine = $tableOptionValue;
break;
case "DEFAULT CHARSET":
case "DEFAULT CHARACTER SET":
case "CHARSET":
case "CHARACTER SET":
$charset = $tableOptionValue;
break;
}
}
$ret['engine'][] = $engine;
$ret['charset'][] = $charset;
}
if(empty($ret['tables']))
{
e107::getMessage()->addDebug("Unable to parse ".$this->currentTable."_sql.php file data. Possibly missing a ';' at the end?");
@@ -1013,7 +1163,7 @@ class db_verify
foreach($tmp as $line)
{
$line = trim($line);
$newline[] = preg_replace("/^([^`A-Z\s][a-z_]*[0-9]?)/","`$1`", $line);
$newline[] = preg_replace('/^([^`\s][0-9a-zA-Z\$_]*)/',"`$1`", $line);
}
$data = implode("\n",$newline);
@@ -1298,6 +1448,90 @@ class db_verify
$ns->tablerender(DBVLAN_23.SEP.DBVLAN_16, $mes->render().$text);
}
/**
* Get the available storage engines on this MySQL server
*
* This method is not memoized and should not be called repeatedly.
*
* @return string[] An unordered list of the storage engines supported by the current MySQL server
*/
private static function getAvailableStorageEngines()
{
$db = e107::getDb();
$db->gen("SHOW ENGINES;");
$output = [];
while ($row = $db->fetch())
{
$output[] = $row['Engine'];
}
return $output;
}
/**
* Get the most compatible MySQL storage engine on this server for the provided storage engine
*
* @param string|null $maybeStorageEngine The requested storage engine
* @return string|false The MySQL storage engine that should actually be used. false if no match found.
*/
public function getIntendedStorageEngine($maybeStorageEngine = null)
{
if ($maybeStorageEngine === null)
return $this->getIntendedStorageEngine(self::MOST_PREFERRED_STORAGE_ENGINE);
if (!array_key_exists($maybeStorageEngine, $this->storageEnginePreferenceMap))
{
if (in_array($maybeStorageEngine, $this->availableStorageEngines))
return $maybeStorageEngine;
return false;
}
$fit = array_intersect($this->storageEnginePreferenceMap[$maybeStorageEngine], $this->availableStorageEngines);
return current($fit);
}
/**
* Try to figure out what storage engine the provided one is referring to
*
* @param string $maybeStorageEngine The reported storage engine
* @return string The probable storage engine the input is referring to
* @throws UnexpectedValueException if the provided storage engine is not known as an available storage engine
*/
public function getCanonicalStorageEngine($maybeStorageEngine)
{
if (in_array($maybeStorageEngine, $this->availableStorageEngines))
return $maybeStorageEngine;
throw new UnexpectedValueException(
"Unknown storage engine: " . var_export($maybeStorageEngine, true)
);
}
/**
* Get the most compatible MySQL character set based on the input
*
* @param string|null $maybeCharset The requested character set. null to retrieve the default
* @return string The MySQL character set that should actually be used
*/
public function getIntendedCharset($maybeCharset = null)
{
if (empty($maybeCharset)) return self::MOST_PREFERRED_CHARSET;
return $this->getCanonicalCharset($maybeCharset);
}
/**
* Try to figure out what character set the provided one is referring to
*
* @param string $maybeCharset The reported character set
* @return string The probable character set
*/
public function getCanonicalCharset($maybeCharset)
{
if ($maybeCharset == "utf8") return "utf8mb4";
return $maybeCharset;
}
}

View File

@@ -2610,11 +2610,11 @@ class e_db_pdo implements e_db
/**
* Set Database charset to utf8
* Set Database charset to utf8mb4
*
* @access private
*/
public function setCharset($charset = 'utf8')
public function setCharset($charset = 'utf8mb4')
{
$this->db_Query("SET NAMES `$charset`");
@@ -2627,7 +2627,8 @@ class e_db_pdo implements e_db
*/
public function getCharset()
{
return $this->mySQLcharset;
require_once(e_HANDLER."db_verify_class.php");
return (new db_verify())->getIntendedCharset($this->mySQLcharset);
}

View File

@@ -2450,7 +2450,7 @@ class e_db_mysql implements e_db
/**
* Check if MySQL version is utf8 compatible and may be used as it accordingly to the user choice
* Check if MySQL version is utf8mb4 compatible and may be used as it accordingly to the user choice
*
* @TODO Simplify when the conversion script will be available
* @access public
@@ -2463,15 +2463,16 @@ class e_db_mysql implements e_db
{
// Get the default user choice
global $mySQLcharset;
if (isset($mySQLcharset) && $mySQLcharset != 'utf8')
if (isset($mySQLcharset) && $mySQLcharset != 'utf8mb4')
{
// Only utf8 is accepted
// Only utf8mb4 is accepted
$mySQLcharset = '';
}
$charset = ($charset ? $charset : $mySQLcharset);
$message = (( ! $charset && $debug) ? 'Empty charset!' : '');
if($charset)
{
$this->mySQLaccess->set_charset($charset);
if ( ! $debug)
{
@mysqli_query($this->mySQLaccess, "SET NAMES `$charset`");

View File

@@ -3412,9 +3412,8 @@ class e107plugin
return null;
}
/** @var db_verify $dbv */
$dbv = e107::getSingleton('db_verify', e_HANDLER."db_verify_class.php");
// require_once(e_HANDLER."db_verify_class.php");
// $dbv = new db_verify;
$sql = e107::getDb();
// Add or Remove Table --------------
@@ -3436,12 +3435,15 @@ class e107plugin
foreach($tableData['tables'] as $k=>$v)
{
$engine = $dbv->getIntendedStorageEngine($tableData['engine'][$k]);
$charset = $dbv->getIntendedCharset($tableData['charset'][$k]);
switch($function)
{
case "install":
$query = "CREATE TABLE `".MPREFIX.$v."` (\n";
$query .= $tableData['data'][$k];
$query .= "\n) ENGINE=". vartrue($tableData['engine'][$k],"InnoDB")." DEFAULT CHARSET=utf8 ";
$query .= "\n) ENGINE=$engine DEFAULT CHARSET=$charset ";
$txt = EPL_ADLAN_239." <b>{$v}</b> ";
$status = $sql->db_Query($query) ? E_MESSAGE_SUCCESS : E_MESSAGE_ERROR;
@@ -4633,7 +4635,7 @@ class e107plugin
/**
* Installs a plugin by ID or folder name
*
* @param int $id
* @param int|string $id
* @param array $options (currently only 'nolinks' - set to true to prevent sitelink creation during install)
*/
function install($id, $options = array())

View File

@@ -22,6 +22,8 @@ define("DBVLAN_13", "Table missing!");
define("DBVLAN_14", "Choose table(s) to validate");
define("DBVLAN_15", "Start Verify");
define("DBVLAN_16", "SQL Verification");
define("DBVLAN_17", "Storage engine should be [x] but is [y]");
define("DBVLAN_18", "Character set should be [x] but is [y]");
define("DBVLAN_19", "Attempt to Fix");
@@ -32,5 +34,8 @@ define("DBVLAN_24", "Please select action.");
define("DBVLAN_25", "Index missing!");
define("DBVLAN_26", "[x] table(s) have problems.");
// IMPORTANT NOTE: DBLAN has been replaced by DBBLAN in this file since 0.7 due to conflicts with db.php
define("DBVLAN_27", "Table inconsistency");
define("DBVLAN_28", "Not applicable");
// IMPORTANT NOTE: DBLAN has been replaced by DBVLAN in this file since 0.7 due to conflicts with db.php

View File

@@ -98,7 +98,7 @@ class auth_login extends alt_auth_base
*/
// $dsn = 'mysql:dbname=' . $this->conf['e107db_database'] . ';host=' . $this->conf['e107db_server'];
$dsn = "mysql:host=".$this->conf['e107db_server'].";port=".varset($this->conf['e107db_port'],3306).";dbname=".$this->conf['e107db_database'];
$dsn = "mysql:host=".$this->conf['e107db_server'].";port=".varset($this->conf['e107db_port'],3306).";dbname=".$this->conf['e107db_database'].";charset=".(new db_verify())->getIntendedCharset();
try
{

View File

@@ -81,7 +81,7 @@ class auth_login extends alt_auth_base
{
/* Begin - Deltik's PDO Workaround (part 1/2) */
// $dsn = 'mysql:dbname=' . $this->conf['otherdb_database'] . ';host=' . $this->conf['otherdb_server'];
$dsn = "mysql:host=".$this->conf['otherdb_server'].";port=".varset($this->conf['otherdb_port'],3306).";dbname=".$this->conf['otherdb_database'];
$dsn = "mysql:host=".$this->conf['otherdb_server'].";port=".varset($this->conf['otherdb_port'],3306).";dbname=".$this->conf['otherdb_database'].";charset=".(new db_verify())->getIntendedCharset();
try

View File

@@ -49,6 +49,8 @@
table_summary text,
table_media text,
table_email2 tinyint(3) unsigned NOT NULL default '0',
table_email90 tinyint(3) unsigned NOT NULL default '0',
e107_name varchar(100) NOT NULL default '',
PRIMARY KEY (table_id)";
$expected = array (
@@ -188,6 +190,22 @@
'null' => 'NOT NULL',
'default' => 'DEFAULT \'0\'',
),
'table_email90' =>
array (
'type' => 'TINYINT',
'value' => '3',
'attributes' => 'UNSIGNED',
'null' => 'NOT NULL',
'default' => 'DEFAULT \'0\'',
),
'e107_name' =>
array (
'type' => 'VARCHAR',
'value' => '100',
'attributes' => '',
'null' => 'NOT NULL',
'default' => 'DEFAULT \'\'',
),
);
$actual = $this->dbv->getFields($data);
@@ -402,7 +420,7 @@ EOF;
PRIMARY KEY (table_id)
UNIQUE KEY `table_email` (`table_email`),
KEY `table_user` (`table_user`)
) ENGINE=InnoDB;';
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8mb4;';
$expected = str_replace("\t", "",$expected);
$actual = str_replace("\t", "",$actual);
@@ -809,6 +827,11 @@ EOF;
$fileData['index'] = $this->dbv->getIndex($file);
$sqlData['index'] = $this->dbv->getIndex($sql);
$fileData['engine'] = $this->dbv->getIntendedStorageEngine("InnoDB");
$sqlData['engine'] = $this->dbv->getCanonicalStorageEngine("InnoDB");
$fileData['charset'] = $this->dbv->getIntendedCharset("utf8mb4");
$sqlData['charset'] = $this->dbv->getCanonicalCharset("utf8mb4");
$this->dbv->prepareResults('schedule', 'myplugin', $sqlData, $fileData);
@@ -946,4 +969,75 @@ EOF;
{
}*/
public function testGetCanonicalStorageEngine()
{
$input = "InnoDB";
$output = $this->dbv->getCanonicalStorageEngine($input);
$this->assertEquals($input, $output);
}
public function testGetCanonicalStorageEngineUnknownStorageEngine()
{
$this->expectException(UnexpectedValueException::class);
$this->dbv->getCanonicalStorageEngine("FakeEngine");
}
public function testGetCanonicalCharsetUtf8Alias()
{
$input = "utf8";
$expected = "utf8mb4";
$output = $this->dbv->getCanonicalCharset($input);
$this->assertEquals($expected, $output);
}
public function testGetCanonicalCharsetOther()
{
$inputs = ["latin1", "utf8mb3", "utf8mb4"];
foreach ($inputs as $input)
{
$output = $this->dbv->getCanonicalCharset($input);
$this->assertEquals($input, $output);
}
}
public function testGetIntendedStorageEngine()
{
$output = $this->dbv->getIntendedStorageEngine("MyISAM");
$this->assertEquals("InnoDB", $output);
$output = $this->dbv->getIntendedStorageEngine("InnoDB");
$this->assertEquals("InnoDB", $output);
$output = $this->dbv->getIntendedStorageEngine("Aria");
$this->assertContains($output, ["Aria", "Maria", "MyISAM"]);
$output = $this->dbv->getIntendedStorageEngine("MEMORY");
$this->assertEquals("MEMORY", $output);
}
public function testGetIntendedCharset()
{
$output = $this->dbv->getIntendedCharset("");
$this->assertEquals("utf8mb4", $output);
$output = $this->dbv->getIntendedCharset();
$this->assertEquals("utf8mb4", $output);
$output = $this->dbv->getIntendedCharset("utf8");
$this->assertEquals("utf8mb4", $output);
$output = $this->dbv->getIntendedCharset("utf8mb3");
$this->assertEquals("utf8mb3", $output);
$output = $this->dbv->getIntendedCharset("latin1");
$this->assertEquals("latin1", $output);
}
}

View File

@@ -40,7 +40,7 @@ class e_db_pdoTest extends e_db_abstractTest
$this->db->setCharset();
$result = $this->db->getCharset();
$this->assertEquals('utf8', $result);
$this->assertEquals('utf8mb4', $result);
}
public function testBackup()

View File

@@ -833,13 +833,13 @@ class e_install
if($this->previous_steps['mysql']['createdb'] == 1)
{
$notification = "<br /><span class='glyphicon glyphicon-ok'></span> ".LANINS_044;
$query = 'CREATE DATABASE `'.$this->previous_steps['mysql']['db'].'` CHARACTER SET `utf8` ';
$query = 'CREATE DATABASE `'.$this->previous_steps['mysql']['db'].'` CHARACTER SET `utf8mb4` ';
}
else
{
$notification = "<br /><span class='glyphicon glyphicon-ok'></span> ".LANINS_137;
$query = 'ALTER DATABASE `'.$this->previous_steps['mysql']['db'].'` CHARACTER SET `utf8` ';
$query = 'ALTER DATABASE `'.$this->previous_steps['mysql']['db'].'` CHARACTER SET `utf8mb4` ';
}
if (!$this->dbqry($query))
@@ -854,7 +854,7 @@ class e_install
}
else
{
$this->dbqry('SET NAMES `utf8`');
$this->dbqry('SET NAMES `utf8mb4`');
$page_content .= $notification; // "
}
@@ -1496,7 +1496,7 @@ class e_install
\$mySQLpassword = '{$this->previous_steps['mysql']['password']}';
\$mySQLdefaultdb = '{$this->previous_steps['mysql']['db']}';
\$mySQLprefix = '{$this->previous_steps['mysql']['prefix']}';
\$mySQLcharset = 'utf8';
\$mySQLcharset = 'utf8mb4';
\$ADMIN_DIRECTORY = '{$this->e107->e107_dirs['ADMIN_DIRECTORY']}';
\$FILES_DIRECTORY = '{$this->e107->e107_dirs['FILES_DIRECTORY']}';
@@ -1903,9 +1903,10 @@ if($this->pdo == true)
*/
public function install_plugin($plugpath)
{
e107::getPlugin()->install_plugin($plugpath);
// e107::getPlugin()->install_plugin($row['plugin_id']);
$plugin_handler = e107::getPlugin();
$plugin_handler->XmlTables('uninstall', ['plugin_path' => $plugpath], ['delete_tables' => true]);
$plugin_handler->install($plugpath);
e107::getMessage()->reset(false, false, true);
return null;
@@ -2165,7 +2166,7 @@ if($this->pdo == true)
preg_match_all("/create(.*?)(?:myisam|innodb);/si", $sql_data, $result );
// Force UTF-8 again
$this->dbqry('SET NAMES `utf8`');
$this->dbqry('SET NAMES `utf8mb4`');
$srch = array("CREATE TABLE","(");
$repl = array("DROP TABLE IF EXISTS","");