using Tiobon.Core.OPS.Tool.OPS.Tool.Helper; using MySql.Data.MySqlClient; using System; using System.Collections.Generic; using System.ComponentModel; using System.Data; using System.Drawing; using System.IO; using System.Linq; using System.Text; using System.Windows.Forms; namespace Tiobon.Core.OPS.Tool.OPS.Tool.View { public partial class Frm_DBCompare_Step2 : Form { #region 初始化 string m_HdisConnStr = ""; string m_ConnStr = ""; string m_Version = ""; SSHHelper sSH; public Frm_DBCompare_Step2(string hdisConnStr, string connStr, string ver, SSHHelper sSH, FormWindowState windowState) { InitializeComponent(); m_ConnStr = connStr; m_HdisConnStr = hdisConnStr; m_Version = ver; this.sSH = sSH; WindowState = windowState; } private void Frm_DBCompare_Step2_Load(object sender, EventArgs e) { this.txt_fname.Text = $"{Environment.GetFolderPath(Environment.SpecialFolder.DesktopDirectory)}\\数据结构比对结果_{DateTime.Now.ToString("yyyy_MM_dd")}.sql"; timer_Main.Start(); } bool m_Stop = false; private void Frm_DBCompare_Step2_FormClosing(object sender, FormClosingEventArgs e) { m_Stop = true; } #endregion #region 日志操作 private static List m_LogsTemp = new List(); private void timer_Main_Tick(object sender, EventArgs e) { try { lock (m_Logs) { m_LogsTemp.Clear(); m_Logs.ForEach(log => m_LogsTemp.Add(log)); m_Logs.Clear(); } if (m_LogsTemp.Count > 0) { if (this.lb_Logger.Items.Count > 2000) this.lb_Logger.Items.Clear(); m_LogsTemp.ForEach(log => this.lb_Logger.Items.Add(log)); this.lb_Logger.TopIndex = this.lb_Logger.Items.Count - 1; } lock (m_LockContent) { if (!string.IsNullOrEmpty(m_Content)) { if (m_Content == "clear") { this.rtb_Sql.Text = string.Empty; } else { this.rtb_Sql.Text = m_Content; } m_Content = string.Empty; } } lock (m_LockProgressBar) { progressBar_Main.Maximum = m_PBMax; progressBar_Main.Value = m_PBValue; } } catch { } } private static List m_Logs = new List(); private void SendLog(string oprator, string msg) { lock (m_Logs) { Const.write_log($"[{oprator}] {msg}"); if (string.IsNullOrEmpty(oprator)) m_Logs.Add($"{DateTime.Now.ToString("HH:mm:ss")} {msg}"); else m_Logs.Add($"{DateTime.Now.ToString("HH:mm:ss")} [{oprator}] {msg}"); } } #endregion #region 下一步 bool b_save = false; private void btn_Next_Click(object sender, EventArgs e) { //if (!b_save) //{ // var item = this.rtb_Sql.Text.Split(new string[] { "\n" }, StringSplitOptions.RemoveEmptyEntries).ToList(); // bool isNext = item.Count == 2; // if (!string.IsNullOrEmpty(this.rtb_Sql.Text) && !isNext) // { // MessageBox.Show("比对已完成,但是结果未保存或复制!", "提示"); // b_save = true; // return; // } //} this.Hide(); using (Frm_DBCompare_Step3 f = new Frm_DBCompare_Step3(m_HdisConnStr, m_ConnStr, m_Version, sSH, WindowState)) { f.ShowDialog(); } } #endregion #region 执行比对 int m_PBMax = 0; int m_PBValue = 0; object m_LockProgressBar = new object(); bool b_In = false; object m_LockIn = new object(); private void btn_Compare_Click(object sender, EventArgs e) { lock (m_LockIn) { if (b_In) { return; } else { b_In = true; } } new System.Threading.Thread(Compare).Start(); } string m_Content = string.Empty; object m_LockContent = new object(); private void Compare() { int sum = 0; StringBuilder sb = new StringBuilder(); try { #region step 1.1 加载表结构 // 源数据库 string sql = $"SELECT * FROM INFORMATION_SCHEMA.`COLUMNS` C WHERE C.TABLE_SCHEMA = 'hdis_compare';"; DataTable dt = MySqlHelper.ExecuteDataset(m_ConnStr, sql).Tables[0]; List srcCloumns = dt .AsEnumerable() .Select(o => new CompareStructureCloumn { TableName = o.Field("TABLE_NAME"), ColumnName = o.Field("COLUMN_NAME"), DefaultValue = o.Field("COLUMN_DEFAULT"), Null = o.Field("IS_NULLABLE"), DataType = o.Field("COLUMN_TYPE"), Key = o.Field("COLUMN_KEY"), Collsion = o.Field("COLLATION_NAME"), CharacterSet = o.Field("CHARACTER_SET_NAME") }) .ToList(); SendLog("", $"加载源数据库[hdis_compare]信息完毕:共有表{srcCloumns.Select(o => o.TableName).Distinct().Count()} 字段 {srcCloumns.Count}"); // 目标数据库 sql = $"SELECT * FROM INFORMATION_SCHEMA.`COLUMNS` C WHERE C.TABLE_SCHEMA = 'hdis';"; dt = MySqlHelper.ExecuteDataset(m_ConnStr, sql).Tables[0]; List desrcCloumns = dt .AsEnumerable() .Select(o => new CompareStructureCloumn { TableName = o.Field("TABLE_NAME"), ColumnName = o.Field("COLUMN_NAME"), DefaultValue = o.Field("COLUMN_DEFAULT"), Null = o.Field("IS_NULLABLE"), DataType = o.Field("COLUMN_TYPE"), Key = o.Field("COLUMN_KEY"), Collsion = o.Field("COLLATION_NAME"), CharacterSet = o.Field("CHARACTER_SET_NAME") }) .ToList(); SendLog("", $"加载目标数据库[hdis]信息完毕:共有表{desrcCloumns.Select(o => o.TableName).Distinct().Count()} 字段 {desrcCloumns.Count}"); #region 1.2 加载外键 sql = @"SELECT T.TABLE_NAME, T.CONSTRAINT_NAME, T.CONSTRAINT_TYPE, K.COLUMN_NAME, K.REFERENCED_TABLE_NAME, K.REFERENCED_COLUMN_NAME FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS T JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE K ON T.CONSTRAINT_SCHEMA = K.CONSTRAINT_SCHEMA AND T.TABLE_NAME = K.TABLE_NAME AND T.CONSTRAINT_NAME = K.CONSTRAINT_NAME JOIN INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS R ON T.CONSTRAINT_SCHEMA = R.CONSTRAINT_SCHEMA AND T.TABLE_NAME = R.TABLE_NAME AND T.CONSTRAINT_NAME = R.CONSTRAINT_NAME WHERE R.CONSTRAINT_SCHEMA = '{0}' AND T.CONSTRAINT_TYPE <> 'PRIMARY KEY';"; // 源数据库 dt = MySqlHelper.ExecuteDataset(m_ConnStr, string.Format(sql, "hdis_compare")).Tables[0]; List srcConstraints = dt .AsEnumerable() .Select(m => new TableConstraint() { TABLE_NAME = m.Field(nameof(TableConstraint.TABLE_NAME)), CONSTRAINT_NAME = m.Field(nameof(TableConstraint.CONSTRAINT_NAME)), CONSTRAINT_TYPE = m.Field(nameof(TableConstraint.CONSTRAINT_TYPE)), COLUMN_NAME = m.Field(nameof(TableConstraint.COLUMN_NAME)), REFERENCED_TABLE_NAME = m.Field(nameof(TableConstraint.REFERENCED_TABLE_NAME)), REFERENCED_COLUMN_NAME = m.Field(nameof(TableConstraint.REFERENCED_COLUMN_NAME)) }) .ToList(); SendLog("", $"加载源数据库[hdis_compare]外键完毕:共有外键 {srcConstraints.Count} 条"); // 目标据库 dt = MySqlHelper.ExecuteDataset(m_ConnStr, string.Format(sql, "hdis")).Tables[0]; List destConstraints = dt .AsEnumerable() .Select(m => new TableConstraint() { TABLE_NAME = m.Field(nameof(TableConstraint.TABLE_NAME)), CONSTRAINT_NAME = m.Field(nameof(TableConstraint.CONSTRAINT_NAME)), CONSTRAINT_TYPE = m.Field(nameof(TableConstraint.CONSTRAINT_TYPE)), COLUMN_NAME = m.Field(nameof(TableConstraint.COLUMN_NAME)), REFERENCED_TABLE_NAME = m.Field(nameof(TableConstraint.REFERENCED_TABLE_NAME)), REFERENCED_COLUMN_NAME = m.Field(nameof(TableConstraint.REFERENCED_COLUMN_NAME)) }) .ToList(); SendLog("", $"加载目标数据库[hdis]外键完毕:共有外键 {destConstraints.Count} 条"); #endregion #region 1.3 加载索引 sql = @"SELECT TABLE_NAME, NON_UNIQUE, INDEX_NAME, COLUMN_NAME, INDEX_TYPE FROM INFORMATION_SCHEMA.STATISTICS WHERE TABLE_SCHEMA = '{0}' AND INDEX_NAME <> 'PRIMARY';"; // 源数据库 dt = MySqlHelper.ExecuteDataset(m_ConnStr, string.Format(sql, "hdis_compare")).Tables[0]; List srcIndexes = dt .AsEnumerable() .Select(m => new TableIndex() { TABLE_NAME = m.Field(nameof(TableIndex.TABLE_NAME)), NON_UNIQUE = m.Field(nameof(TableIndex.NON_UNIQUE)), INDEX_NAME = m.Field(nameof(TableIndex.INDEX_NAME)), COLUMN_NAME = m.Field(nameof(TableIndex.COLUMN_NAME)), INDEX_TYPE = m.Field(nameof(TableIndex.INDEX_TYPE)) }) .ToList(); SendLog("", $"加载源数据库[hdis_compare]索引完毕:共有索引 {srcConstraints.Count} 条"); // 源数据库 dt = MySqlHelper.ExecuteDataset(m_ConnStr, string.Format(sql, "hdis")).Tables[0]; List destIndexes = dt .AsEnumerable() .Select(m => new TableIndex() { TABLE_NAME = m.Field(nameof(TableIndex.TABLE_NAME)), NON_UNIQUE = m.Field(nameof(TableIndex.NON_UNIQUE)), INDEX_NAME = m.Field(nameof(TableIndex.INDEX_NAME)), COLUMN_NAME = m.Field(nameof(TableIndex.COLUMN_NAME)), INDEX_TYPE = m.Field(nameof(TableIndex.INDEX_TYPE)) }) .ToList(); SendLog("", $"加载目标数据库[hdis]索引完毕:共有索引 {srcConstraints.Count} 条"); #endregion sum = 6; lock (m_LockProgressBar) { m_PBMax = sum; } #endregion #region step 2 比对数据库结构 SendLog("", "开始比较数据库结构"); #region 2.1 比较字段 var sExcept = srcCloumns.Except(desrcCloumns, new CompareStructureCloumnComparer()).ToList(); var dExcept = desrcCloumns.Except(srcCloumns, new CompareStructureCloumnComparer()).ToList(); var except = new List(); dExcept.ForEach(o => { if (m_Stop) return; bool has = false; sExcept.ForEach(p => { if (m_Stop) return; //具有相同的两个重复记录 if (o.TableName == p.TableName && o.ColumnName == p.ColumnName) { has = true; return; } }); if (!has) { except.Add(o); } }); except = except.Union(sExcept).ToList(); SendLog("", "字段比较完毕"); if (except.Count <= 0) { SendLog("", "数据结构完全一致"); return; } lock (m_LockProgressBar) { m_PBValue = 1; } #endregion #region 2.2 生成需要创建的表 bool b_hasConetnt = false; sb.AppendLine("SET FOREIGN_KEY_CHECKS = 0;\r\n"); var temp = except.Select(o => o.TableName).Distinct(); SendLog("", $"字段不同数量为 {except.Count}"); var sTempNames = srcCloumns.Select(o => o.TableName); var dTempNames = desrcCloumns.Select(o => o.TableName); var createTablesNames = temp.Where(o => !dTempNames.Contains(o)).ToList(); SendLog("", $"生成需要创建的表 数量 {createTablesNames.Count}"); if (createTablesNames.Any()) { createTablesNames.ForEach(tname => { if (m_Stop) return; DataSet ds = MySqlHelper.ExecuteDataset(m_ConnStr, $"SHOW CREATE TABLE `hdis_compare`.`{tname}`;"); if (ds != null && ds.Tables.Count > 0 && ds.Tables[0].Rows.Count > 0) { b_hasConetnt = true; sb.AppendLine($"{ds.Tables[0].Rows[0][1].ToString()};\r\n"); SendLog("", $"生成表[{tname}]结构语句"); } else { SendLog("", $"生成表[{tname}]结构语句异常,表不存在"); } }); SendLog("", $"生成需要创建的表完毕"); } lock (m_LockProgressBar) { m_PBValue = 2; } #endregion #region 2.3 生成需要删除的表 var deleteTablesNames = temp.Where(o => !sTempNames.Contains(o)).ToList(); SendLog("", $"生成需要删除的表 数量 {deleteTablesNames.Count}"); if (deleteTablesNames.Any()) { deleteTablesNames.ForEach(tname => { b_hasConetnt = true; sb.AppendLine($"DROP TABLE `hdis`.`{tname}`;\r\n"); SendLog("", $"生成表[{tname}]删除语句"); }); SendLog("", $"生成需要删除的表完毕"); } lock (m_LockProgressBar) { m_PBValue = 3; } #endregion #region 2.4 生成需要修改的表 var deletedColumns = new List<(string table, string column)>(); var alterTablesNames = temp.Where(o => dTempNames.Contains(o) && sTempNames.Contains(o)).ToList(); SendLog("", $"生成需要修改的表 数量 {alterTablesNames.Count}"); if (alterTablesNames.Any()) { alterTablesNames.ForEach(o => { #region 2.4.1 创建列语句 except .Where(t => t.TableName == o && !desrcCloumns.Where(p => p.TableName == o).Select(p => p.ColumnName).ToList().Contains(t.ColumnName)) .ToList() .ForEach(t => { b_hasConetnt = true; sb.AppendLine($"ALTER TABLE `hdis`.`{t.TableName}` ADD COLUMN `{t.ColumnName}` {t.DataType}{GetCharacter_Set_Name(t.CharacterSet)}{GetCollate(t.Collsion)}{GetNull(t.Null)}{GetDefaultValue(t.DefaultValue, t.DataType)};\r\n"); }); #endregion #region 2.4.2 删除列语句 except .Where(t => t.TableName == o && !srcCloumns.Where(p => p.TableName == o).Select(p => p.ColumnName).ToList().Contains(t.ColumnName)) .ToList() .ForEach(t => { if (t.ColumnName == "deleted") // 如果添加删除列 deleted,生成删除垃圾数据的语句 { sb.AppendLine($"/* 删除垃圾数据 */"); sb.AppendLine($"DELETE FROM hdis.{t.TableName} WHERE deleted = 1;"); } string forignKey = QueryForignKeyProduct("hdis", tableName: o, colName: t.ColumnName); string indexs = QueryIndexProduct("hdis", tableName: o, colName: t.ColumnName); b_hasConetnt = true; if (!string.IsNullOrEmpty(forignKey)) sb.AppendLine(forignKey); if (!string.IsNullOrEmpty(indexs)) sb.AppendLine(indexs); sb.AppendLine($"ALTER TABLE `hdis`.`{t.TableName}` DROP COLUMN `{t.ColumnName}`;\r\n"); deletedColumns.Add((t.TableName, t.ColumnName)); }); #endregion #region 2.4.3 修改列语句 except .Where(t => t.TableName == o && srcCloumns.Where(p => p.TableName == o).Select(p => p.ColumnName).ToList().Contains(t.ColumnName) && desrcCloumns.Where(p => p.TableName == o).Select(p => p.ColumnName).ToList().Contains(t.ColumnName)) .ToList() .ForEach(t => { b_hasConetnt = true; string renovate = RenovateNotNull("hdis", t.TableName, t.ColumnName, t.Null, t.DefaultValue, t.DataType); sb.AppendLine(renovate); sb.AppendLine($"ALTER TABLE `hdis`.`{t.TableName}` CHANGE `{t.ColumnName}` `{t.ColumnName}` {t.DataType}{GetCharacter_Set_Name(t.CharacterSet)}{GetCollate(t.Collsion)}{GetNull(t.Null)}{GetDefaultValue(t.DefaultValue, t.DataType)};\r\n"); }); #endregion }); SendLog("", $"生成需要删除的表完毕"); } else { SendLog("", $"没有需要修改的表"); } lock (m_LockProgressBar) { m_PBValue = 4; } #endregion #region 2.5 外键 int newConstraintCount = 0; foreach (var constraint in srcConstraints) { if (createTablesNames.Contains(constraint.TABLE_NAME)) { continue; } if (deletedColumns.Contains((constraint.TABLE_NAME, constraint.COLUMN_NAME))) { continue; } if (!destConstraints.Any(x => x.CONSTRAINT_NAME == constraint.CONSTRAINT_NAME && x.TABLE_NAME == constraint.TABLE_NAME && x.COLUMN_NAME == constraint.COLUMN_NAME && x.REFERENCED_TABLE_NAME == constraint.REFERENCED_TABLE_NAME && x.REFERENCED_COLUMN_NAME == constraint.REFERENCED_COLUMN_NAME)) { newConstraintCount++; sb.AppendLine($"ALTER TABLE `hdis`.`{constraint.TABLE_NAME}` ADD CONSTRAINT `{constraint.CONSTRAINT_NAME}` FOREIGN KEY(`{constraint.COLUMN_NAME}`) REFERENCES `{constraint.REFERENCED_TABLE_NAME}` (`{constraint.REFERENCED_COLUMN_NAME}`);"); } } if (newConstraintCount > 0) { b_hasConetnt = true; SendLog("", $"生成需要添加的外键 数量 {newConstraintCount}"); sb.AppendLine(); } else { SendLog("", $"没有需要添加的外键"); } int removeConstraintCount = 0; foreach (var constraint in destConstraints) { if (deletedColumns.Contains((constraint.TABLE_NAME, constraint.COLUMN_NAME))) { continue; } if (!srcConstraints.Any(x => x.CONSTRAINT_NAME == constraint.CONSTRAINT_NAME && x.TABLE_NAME == constraint.TABLE_NAME && x.COLUMN_NAME == constraint.COLUMN_NAME && x.REFERENCED_TABLE_NAME == constraint.REFERENCED_TABLE_NAME && x.REFERENCED_COLUMN_NAME == constraint.REFERENCED_COLUMN_NAME)) { removeConstraintCount++; sb.AppendLine($"ALTER TABLE `hdis`.`{constraint.TABLE_NAME}` DROP FOREIGN KEY `{constraint.CONSTRAINT_NAME}`;"); } } if (removeConstraintCount > 0) { b_hasConetnt = true; SendLog("", $"生成需要删除的外键 数量 {removeConstraintCount}"); sb.AppendLine(); } else { SendLog("", $"没有需要删除的外键"); } lock (m_LockProgressBar) { m_PBValue = 5; } #endregion #region 2.6 索引 int newIndexCount = 0; foreach (var index in srcIndexes) { if (createTablesNames.Contains(index.TABLE_NAME)) { continue; } if (deletedColumns.Contains((index.TABLE_NAME, index.COLUMN_NAME))) { continue; } if (!destIndexes.Any(x => x.INDEX_NAME == index.INDEX_NAME && x.TABLE_NAME == index.TABLE_NAME && x.COLUMN_NAME == index.COLUMN_NAME && x.NON_UNIQUE == index.NON_UNIQUE && x.INDEX_TYPE == index.INDEX_TYPE)) { newIndexCount++; if (index.NON_UNIQUE == 0) { sb.AppendLine($"ALTER TABLE `hdis`.`{index.TABLE_NAME}` ADD UNIQUE INDEX `{index.INDEX_NAME}` (`{index.COLUMN_NAME}`);"); } else if (index.INDEX_TYPE == "FULLTEXT") { sb.AppendLine($"ALTER TABLE `hdis`.`{index.TABLE_NAME}` ADD FULLTEXT INDEX `{index.INDEX_NAME}` (`{index.COLUMN_NAME}`) USING {index.INDEX_TYPE};"); } else if (index.INDEX_TYPE == "SPATIAL") { sb.AppendLine($"ALTER TABLE `hdis`.`{index.TABLE_NAME}` ADD SPATIAL INDEX `{index.INDEX_NAME}` (`{index.COLUMN_NAME}`) USING {index.INDEX_TYPE};"); } else { sb.AppendLine($"ALTER TABLE `hdis`.`{index.TABLE_NAME}` ADD INDEX `{index.INDEX_NAME}` (`{index.COLUMN_NAME}`) USING {index.INDEX_TYPE};"); } } } if (newIndexCount > 0) { b_hasConetnt = true; SendLog("", $"生成需要添加的索引 数量 {newIndexCount}"); sb.AppendLine(); } else { SendLog("", $"没有需要添加的索引"); } int removeIndexCount = 0; foreach (var index in destIndexes) { if (deletedColumns.Contains((index.TABLE_NAME, index.COLUMN_NAME))) { continue; } if (!srcIndexes.Any(x => x.INDEX_NAME == index.INDEX_NAME && x.TABLE_NAME == index.TABLE_NAME && x.COLUMN_NAME == index.COLUMN_NAME && x.NON_UNIQUE == index.NON_UNIQUE && x.INDEX_TYPE == index.INDEX_TYPE)) { removeIndexCount++; sb.AppendLine($"ALTER TABLE `hdis`.`{index.TABLE_NAME}` DROP INDEX `{index.INDEX_NAME}`;"); } } if (removeIndexCount > 0) { b_hasConetnt = true; SendLog("", $"生成需要删除的索引 数量 {removeIndexCount}"); sb.AppendLine(); } else { SendLog("", $"没有需要删除的索引"); } lock (m_LockProgressBar) { m_PBValue = 6; } #endregion sb.AppendLine("SET FOREIGN_KEY_CHECKS = 1;\r\n"); if (m_Stop) return; b_save = false; if (b_hasConetnt) { lock (m_LockContent) m_Content = sb.ToString(); SendLog("", "比较数据库结构完毕"); } else { SendLog("", "比较数据库结构完毕,数据结构完全一致"); lock (m_LockContent) m_Content = "clear"; } #endregion } catch (Exception ex) { SendLog("", $"比对失败:{ex.ToString()}"); } finally { lock (m_LockIn) { b_In = false; } lock (m_LockProgressBar) { m_PBMax = sum; m_PBValue = sum; } } } /// /// /// /// /// private string GetCharacter_Set_Name(string character_set) { return string.IsNullOrEmpty(character_set) ? "" : $" CHARACTER SET '{character_set}'"; } /// /// /// /// /// private string GetCollate(string collate) { return string.IsNullOrEmpty(collate) ? "" : $" COLLATE '{collate}'"; } /// /// /// /// /// private string GetNull(string isnull) { return isnull.ToUpper() == "NO" ? " NOT NULL" : " NULL"; } /// /// 涉及到结构改为非空需要特殊处理 /// /// private string RenovateNotNull(string database, string tablename, string column, string isNull, string defaultValue, string colType) { StringBuilder temp = new StringBuilder(); //变为非空 if (isNull.ToUpper() == "NO") { if (!string.IsNullOrEmpty(defaultValue)) { temp.AppendLine($"#修改表{tablename}的列{column}为非空,有默认值的情况下,将非空字段的为NULL值的数据赋值为默认值。"); temp.AppendLine($"UPDATE `{database}`.`{tablename}` SET `{column}` = {GetDefaultValue(defaultValue, colType, true)} WHERE `{column}` IS NULL;\r\n"); } else { temp.AppendLine($"#修改表{tablename}的列{column}为非空,但此时无默认值,请自主判断该列是否应为非空."); } } return temp.ToString(); } /// /// /// /// /// /// private string GetDefaultValue(string defaultValue, string datetype, bool update = false) { return defaultValue == null ? "" : datetype.Contains("char(36)") || datetype.Contains("varchar") || datetype.Contains("text") || datetype.Contains("json") ? $" {(update ? "" : "DEFAULT")} '{defaultValue}'" : $" {(update ? "" : "DEFAULT")} {defaultValue}"; } #endregion #region 拷贝 private void ll_Copy_LinkClicked(object sender, LinkLabelLinkClickedEventArgs e) { if (string.IsNullOrEmpty(this.rtb_Sql.Text)) { return; } try { b_save = true; Clipboard.SetDataObject(this.rtb_Sql.Text.Trim(), true); MessageBox.Show("拷贝成功!", "提示"); } catch (Exception ex) { MessageBox.Show(ex.Message); } } #endregion #region 保存至文件 private void btn_select_Click(object sender, EventArgs e) { if (string.IsNullOrEmpty(this.rtb_Sql.Text)) { return; } try { string fname = ""; using (FolderBrowserDialog path = new FolderBrowserDialog()) { if (path.ShowDialog() == DialogResult.OK) { fname = $"{ path.SelectedPath}\\ihdis_struct_{DateTime.Now.ToString("yyyy_MM_dd")}.sql"; if (System.IO.File.Exists(fname)) { if (MessageBox.Show("文件已存在,是否覆盖?", "警告", MessageBoxButtons.YesNo, MessageBoxIcon.Warning) == DialogResult.No) { return; } } } } if (!string.IsNullOrEmpty(fname)) { //System.IO.File.WriteAllText(fname, this.rtb_Sql.Text, Encoding.UTF8); var utf8WithBom = new System.Text.UTF8Encoding(false); // 用true来指定包含bom using (StreamWriter sw = new StreamWriter(fname, false, utf8WithBom)) { sw.Write(this.rtb_Sql.Text); } MessageBox.Show($"文件保存成功:\r\n{fname}", "提示"); b_save = true; } } catch (Exception ex) { MessageBox.Show($"文件保存失败:{ex.ToString()}"); } } #endregion #region 查询并生成外键约束,索引约束删除语句 /// /// 查询并生成外键约束删除语句 /// /// /// /// /// public string QueryForignKeyProduct(string database, string tableName, string colName) { string sql = $"select CONSTRAINT_NAME from information_schema.KEY_COLUMN_USAGE p WHERE p.TABLE_SCHEMA = '{database}' AND p.TABLE_NAME = '{tableName}' AND p.COLUMN_NAME = '{colName}'"; DataTable dt = MySqlHelper.ExecuteDataset(m_ConnStr, sql).Tables[0]; string forignName = dt.AsEnumerable().Select(o => new { CONSTRAINT_NAME = o.Field("CONSTRAINT_NAME") }).FirstOrDefault()?.CONSTRAINT_NAME; if (!string.IsNullOrEmpty(forignName)) { string temp = $"ALTER TABLE {database}.`{tableName}` DROP FOREIGN KEY `{forignName}`;"; return temp; } return string.Empty; } /// /// /// /// /// /// public string QueryIndexProduct(string database, string tableName, string colName) { string sql = $"show index from {database}.{tableName} WHERE COLUMN_name = '{colName}';"; DataTable dt = MySqlHelper.ExecuteDataset(m_ConnStr, sql).Tables[0]; string indexName = dt.AsEnumerable().Select(o => new { Key_name = o.Field("Key_name") }).FirstOrDefault()?.Key_name; if (!string.IsNullOrEmpty(indexName)) { string temp = $"ALTER TABLE {database}.`{tableName}` DROP INDEX `{indexName}`; "; return temp; } return string.Empty; } #endregion /// /// 比对ts数据库 /// /// /// private void btn_ts_Click(object sender, EventArgs e) { lock (m_LockIn) { if (b_In) { return; } else { b_In = true; } } new System.Threading.Thread(CompareTs).Start(); } /// /// 比对ts数据库 /// /// private void CompareTs() { int sum = 0; StringBuilder sb = new StringBuilder(); try { #region step 1 加载表结构 //源数据库 string sql = $"SELECT * FROM INFORMATION_SCHEMA.`COLUMNS` C WHERE C.TABLE_SCHEMA = 'ihdis_ts_compare';"; DataTable dt = MySqlHelper.ExecuteDataset(m_ConnStr, sql).Tables[0]; List srcCloumns = dt .AsEnumerable() .Select(o => new CompareStructureCloumn { TableName = o.Field("TABLE_NAME"), ColumnName = o.Field("COLUMN_NAME"), DefaultValue = o.Field("COLUMN_DEFAULT"), Null = o.Field("IS_NULLABLE"), DataType = o.Field("COLUMN_TYPE"), Key = o.Field("COLUMN_KEY"), Collsion = o.Field("COLLATION_NAME"), CharacterSet = o.Field("CHARACTER_SET_NAME") }) .ToList(); SendLog("", $"加载源数据库[ihdis_ts_compare]信息完毕:共有表{srcCloumns.Select(o => o.TableName).Distinct().Count()} 字段 {srcCloumns.Count}"); //目标数据库 sql = $"SELECT * FROM INFORMATION_SCHEMA.`COLUMNS` C WHERE C.TABLE_SCHEMA = 'ihdis_ts';"; dt = MySqlHelper.ExecuteDataset(m_ConnStr, sql).Tables[0]; List desrcCloumns = dt .AsEnumerable() .Select(o => new CompareStructureCloumn { TableName = o.Field("TABLE_NAME"), ColumnName = o.Field("COLUMN_NAME"), DefaultValue = o.Field("COLUMN_DEFAULT"), Null = o.Field("IS_NULLABLE"), DataType = o.Field("COLUMN_TYPE"), Key = o.Field("COLUMN_KEY"), Collsion = o.Field("COLLATION_NAME"), CharacterSet = o.Field("CHARACTER_SET_NAME") }) .ToList(); sum = 4; SendLog("", $"加载源数据库[ihdis_ts]信息完毕:共有表{desrcCloumns.Select(o => o.TableName).Distinct().Count()} 字段 {desrcCloumns.Count}"); lock (m_LockProgressBar) { m_PBMax = sum; } #endregion #region step 2 比对数据库结构 SendLog("", "开始比较数据库结构"); #region 2.1 比较字段 var sExcept = srcCloumns.Except(desrcCloumns, new CompareStructureCloumnComparer()).ToList(); var dExcept = desrcCloumns.Except(srcCloumns, new CompareStructureCloumnComparer()).ToList(); var except = new List(); dExcept.ForEach(o => { if (m_Stop) return; bool has = false; sExcept.ForEach(p => { if (m_Stop) return; //具有相同的两个重复记录 if (o.TableName == p.TableName && o.ColumnName == p.ColumnName) { has = true; return; } }); if (!has) { except.Add(o); } }); except = except.Union(sExcept).ToList(); SendLog("", "字段比较完毕"); if (except == null) { SendLog("", "数据结构完全一致"); return; } lock (m_LockProgressBar) { m_PBValue = 1; } #endregion #region 2.2 生成需要创建的表 bool b_hasConetnt = false; sb.AppendLine("SET FOREIGN_KEY_CHECKS = 0;\r\n"); var temp = except.Select(o => o.TableName).Distinct(); SendLog("", $"字段不同数量为 {except.Count}"); var sTempNames = srcCloumns.Select(o => o.TableName); var dTempNames = desrcCloumns.Select(o => o.TableName); var createTablesNames = temp.Where(o => !dTempNames.Contains(o)).ToList(); SendLog("", $"生成需要创建的表 数量 {createTablesNames.Count}"); if (createTablesNames.Any()) { createTablesNames.ForEach(tname => { if (m_Stop) return; DataSet ds = MySqlHelper.ExecuteDataset(m_ConnStr, $"SHOW CREATE TABLE `ihdis_ts_compare`.`{tname}`;"); if (ds != null && ds.Tables.Count > 0 && ds.Tables[0].Rows.Count > 0) { b_hasConetnt = true; sb.AppendLine($"{ds.Tables[0].Rows[0][1].ToString()};\r\n"); SendLog("", $"生成表[{tname}]结构语句"); } else { SendLog("", $"生成表[{tname}]结构语句异常,表不存在"); } }); SendLog("", $"生成需要创建的表完毕"); } lock (m_LockProgressBar) { m_PBValue = 2; } #endregion #region 2.3 生成需要删除的表 var deleteTablesNames = temp.Where(o => !sTempNames.Contains(o)).ToList(); SendLog("", $"生成需要删除的表 数量 {deleteTablesNames.Count}"); if (deleteTablesNames.Any()) { deleteTablesNames.ForEach(tname => { b_hasConetnt = true; sb.AppendLine($"DROP TABLE `ihdis_ts`.`{tname}`;\r\n"); SendLog("", $"生成表[{tname}]删除语句"); }); SendLog("", $"生成需要删除的表完毕"); } lock (m_LockProgressBar) { m_PBValue = 3; } #endregion #region 2.4 生成需要修改的表 var alterTablesNames = temp.Where(o => dTempNames.Contains(o) && sTempNames.Contains(o)).ToList(); SendLog("", $"生成需要修改的表 数量 {alterTablesNames.Count}"); if (alterTablesNames.Any()) { alterTablesNames.ForEach(o => { #region 2.4.1 创建列语句 except .Where(t => t.TableName == o && !desrcCloumns.Where(p => p.TableName == o).Select(p => p.ColumnName).ToList().Contains(t.ColumnName)) .ToList() .ForEach(t => { b_hasConetnt = true; sb.AppendLine($"ALTER TABLE `ihdis_ts`.`{t.TableName}` ADD COLUMN `{t.ColumnName}` {t.DataType}{GetCharacter_Set_Name(t.CharacterSet)}{GetCollate(t.Collsion)}{GetNull(t.Null)}{GetDefaultValue(t.DefaultValue, t.DataType)};\r\n"); }); #endregion #region 2.4.2 删除列语句 except .Where(t => t.TableName == o && !srcCloumns.Where(p => p.TableName == o).Select(p => p.ColumnName).ToList().Contains(t.ColumnName)) .ToList() .ForEach(t => { if (t.ColumnName == "deleted") // 如果添加删除列 deleted,生成删除垃圾数据的语句 { sb.AppendLine($"/* 删除垃圾数据 */"); sb.AppendLine($"DELETE FROM `ihdis_ts`.{t.TableName} WHERE deleted = 1;"); } string forignKey = QueryForignKeyProduct("ihdis_ts", tableName: o, colName: t.ColumnName); string indexs = QueryIndexProduct("ihdis_ts", tableName: o, colName: t.ColumnName); b_hasConetnt = true; if (!string.IsNullOrEmpty(forignKey)) sb.AppendLine(forignKey); if (!string.IsNullOrEmpty(indexs)) sb.AppendLine(indexs); sb.AppendLine($"ALTER TABLE `ihdis_ts`.`{t.TableName}` DROP COLUMN `{t.ColumnName}`;\r\n"); }); #endregion #region 2.4.3 修改列语句 except .Where(t => t.TableName == o && srcCloumns.Where(p => p.TableName == o).Select(p => p.ColumnName).ToList().Contains(t.ColumnName) && desrcCloumns.Where(p => p.TableName == o).Select(p => p.ColumnName).ToList().Contains(t.ColumnName)) .ToList() .ForEach(t => { b_hasConetnt = true; string renovate = RenovateNotNull("ihdis_ts", t.TableName, t.ColumnName, t.Null, t.DefaultValue, t.DataType); sb.AppendLine(renovate); sb.AppendLine($"ALTER TABLE `ihdis_ts`.`{t.TableName}` CHANGE `{t.ColumnName}` `{t.ColumnName}` {t.DataType}{GetCharacter_Set_Name(t.CharacterSet)}{GetCollate(t.Collsion)}{GetNull(t.Null)}{GetDefaultValue(t.DefaultValue, t.DataType)};\r\n"); }); #endregion }); SendLog("", $"生成需要删除的表完毕"); } else { SendLog("", $"没有需要修改的表"); } lock (m_LockProgressBar) { m_PBValue = 4; } #endregion sb.AppendLine("SET FOREIGN_KEY_CHECKS = 1;\r\n"); if (m_Stop) return; b_save = false; if (b_hasConetnt) { lock (m_LockContent) m_Content = sb.ToString(); SendLog("", "比较数据库结构完毕"); } else { SendLog("", "比较数据库结构完毕,数据结构完全一致"); lock (m_LockContent) m_Content = "clear"; } #endregion } catch (Exception ex) { SendLog("", $"比对失败:{ex.ToString()}"); } finally { lock (m_LockIn) { b_In = false; } lock (m_LockProgressBar) { m_PBMax = sum; m_PBValue = sum; } } } bool b_execsql = false; private void Frm_DBCompare_Step2_KeyDown(object sender, KeyEventArgs e) { if (b_execsql) return; b_execsql = true; if (e.KeyCode == Keys.F5) { if (!string.IsNullOrEmpty(this.rtb_Sql.Text) && MessageBox.Show($"是否确定执行sql语句?", "提示", MessageBoxButtons.YesNo, MessageBoxIcon.Question) == DialogResult.Yes) { try { int res = MySqlHelper.ExecuteNonQuery(m_ConnStr.Replace("jlmedcompare", "jlmed"), this.rtb_Sql.Text); SendLog("执行sql", $"sql语句执行完毕 {res}"); } catch (Exception ex) { SendLog("执行sql", $"sql语句执行失败 {ex.ToString()}"); } } } b_execsql = false; } private void gb_up_Enter(object sender, EventArgs e) { } } #region 表信息 /// /// 表信息 /// public class CompareStructureCloumn { /// /// 表名称 /// public string TableName { set; get; } /// /// 字段名称 /// public string ColumnName { set; get; } /// /// 数据类型 /// public string DataType { set; get; } /// /// 字符集 /// public string CharacterSet { set; get; } /// /// /// public string Collsion { set; get; } /// /// 是否为空 /// public string Null { set; get; } /// /// 默认值 /// public string DefaultValue { set; get; } /// /// 键 /// public string Key { set; get; } } #endregion #region 表约束信息 class TableConstraint { public string TABLE_NAME { get; set; } public string CONSTRAINT_NAME { get; set; } public string CONSTRAINT_TYPE { get; set; } public string COLUMN_NAME { get; set; } public string REFERENCED_TABLE_NAME { get; set; } public string REFERENCED_COLUMN_NAME { get; set; } } #endregion #region 表索引信息 class TableIndex { public string TABLE_NAME { get; set; } public long NON_UNIQUE { get; set; } public string INDEX_NAME { get; set; } public string COLUMN_NAME { get; set; } public string INDEX_TYPE { get; set; } } #endregion #region 自定义比对器 /// /// 自定义比对器 /// public class CompareStructureCloumnComparer : IEqualityComparer { /// /// 比对规则 /// /// /// /// public bool Equals(CompareStructureCloumn x, CompareStructureCloumn y) { var b = x.TableName == y.TableName && x.ColumnName == y.ColumnName && x.CharacterSet == y.CharacterSet && (x.Collsion == y.Collsion) && x.DataType == y.DataType && x.DefaultValue == y.DefaultValue && x.Key == y.Key && x.Null == y.Null; return b; } /// /// /// /// /// public int GetHashCode(CompareStructureCloumn obj) { return obj.ToString().GetHashCode(); } } #endregion }