Updated SqlBuilder
This commit is contained in:
@@ -196,6 +196,18 @@ namespace DbTools.Model {
|
||||
return SqlScript;
|
||||
}
|
||||
|
||||
/// <summary>
|
||||
/// Imports the schema and metadata from the connected SQLite database into the application's internal
|
||||
/// structures.
|
||||
/// </summary>
|
||||
/// <remarks>This method reads the SQLite database schema, including tables, indexes, and
|
||||
/// triggers, and populates the application's internal collections with the corresponding metadata. It
|
||||
/// processes the `sqlite_master` table to extract the necessary information and organizes it into tables,
|
||||
/// indexes, and triggers. <para> The method clears any existing table metadata before importing new data. It
|
||||
/// also formats the SQL definitions for tables to improve readability. </para> <para> This method assumes that
|
||||
/// the database connection is already open and accessible. Ensure that the connection is valid before calling
|
||||
/// this method. </para></remarks>
|
||||
/// <returns><see langword="true"/> if the import operation completes successfully.</returns>
|
||||
private bool importFromSqlite() {
|
||||
DbConnection.Open();
|
||||
Tables.Clear();
|
||||
@@ -264,6 +276,16 @@ namespace DbTools.Model {
|
||||
return true;
|
||||
}
|
||||
|
||||
/// <summary>
|
||||
/// Appends index definitions to the corresponding tables in the database schema.
|
||||
/// </summary>
|
||||
/// <remarks>This method updates the <c>Indexes</c> collection of each table in the <c>Tables</c>
|
||||
/// dictionary with the provided index definitions. If a table does not exist in the <c>Tables</c> dictionary,
|
||||
/// it is skipped. Only valid index definitions (those containing both a name and a SQL definition) are
|
||||
/// added.</remarks>
|
||||
/// <param name="indexes">A dictionary where the key is the name of a table, and the value is a list of index definitions. Each index
|
||||
/// definition is a semicolon-separated string, where the first part is the index name and the second part is
|
||||
/// the index SQL definition.</param>
|
||||
private void appendIndexes(Dictionary<string, List<string>> indexes) {
|
||||
foreach (string index in indexes.Keys) {
|
||||
Table table = Tables[index];
|
||||
@@ -278,6 +300,16 @@ namespace DbTools.Model {
|
||||
}
|
||||
}
|
||||
|
||||
/// <summary>
|
||||
/// Appends trigger definitions to the corresponding tables in the database schema.
|
||||
/// </summary>
|
||||
/// <remarks>This method updates the <see cref="Table.Triggers"/> collection for each table
|
||||
/// specified in the <paramref name="triggers"/> dictionary. If a table does not exist in the <see
|
||||
/// cref="Tables"/> collection, it is skipped. Only trigger definitions with a valid format (name and SQL body
|
||||
/// separated by a semicolon) are added.</remarks>
|
||||
/// <param name="triggers">A dictionary where each key represents the name of a table, and the associated value is a list of trigger
|
||||
/// definitions for that table. Each trigger definition is a string containing the trigger name and its SQL
|
||||
/// body, separated by a semicolon.</param>
|
||||
private void appendTriggers(Dictionary<string, List<string>> triggers) {
|
||||
foreach (string trigger in triggers.Keys) {
|
||||
Table table = Tables[trigger];
|
||||
|
||||
255
SqlBuilder.cs
255
SqlBuilder.cs
@@ -1,11 +1,22 @@
|
||||
using System;
|
||||
using System.Collections.Generic;
|
||||
using System.Data;
|
||||
using System.Diagnostics;
|
||||
using System.Text;
|
||||
using System.Text.RegularExpressions;
|
||||
|
||||
namespace DbTools {
|
||||
public class SqlBuilder {
|
||||
|
||||
/// <summary>
|
||||
/// Retrieves the names of all user-defined tables in the connected SQLite database.
|
||||
/// </summary>
|
||||
/// <remarks>System tables (e.g., those starting with "sqlite_") are excluded from the results.
|
||||
/// The method ensures the connection is open before executing the query.</remarks>
|
||||
/// <param name="cn">An open <see cref="IDbConnection"/> to the SQLite database. The connection must not be null.</param>
|
||||
/// <returns>An array of strings containing the names of all user-defined tables in the database. The array will be empty
|
||||
/// if no tables are found.</returns>
|
||||
/// <exception cref="ArgumentNullException">Thrown if <paramref name="cn"/> is <see langword="null"/>.</exception>
|
||||
public string[] GetTableNames(IDbConnection cn) {
|
||||
if (cn == null) {
|
||||
throw new ArgumentNullException("cn");
|
||||
@@ -25,7 +36,23 @@ namespace DbTools {
|
||||
return tables.ToArray();
|
||||
}
|
||||
|
||||
public string GetTableCreateSql(IDbConnection cn, string tableName, string selectStatement = "select * from $table") {
|
||||
/// <summary>
|
||||
/// Generates the SQL script to recreate the specified table, including its schema, indexes, triggers, and
|
||||
/// optionally its data.
|
||||
/// </summary>
|
||||
/// <remarks>The generated script includes the table's schema, indexes, and triggers. If a
|
||||
/// <paramref name="selectStatement"/> is provided, the script will also include the data returned by the SELECT
|
||||
/// statement. The method ensures the database connection is open before executing any commands.</remarks>
|
||||
/// <param name="cn">The database connection to use. The connection must be to a SQLite database and can be in any state; the
|
||||
/// method will ensure it is open.</param>
|
||||
/// <param name="tableName">The name of the table for which to generate the SQL script. Cannot be <see langword="null"/> or empty.</param>
|
||||
/// <param name="selectStatement">An optional SQL SELECT statement to retrieve data from the table. If provided, the script will include the
|
||||
/// data as part of the output.</param>
|
||||
/// <returns>A string containing the SQL script to recreate the table, including its schema, indexes, triggers, and
|
||||
/// optionally its data. Returns an empty string if the table's schema cannot be determined.</returns>
|
||||
/// <exception cref="ArgumentNullException">Thrown if <paramref name="cn"/> is <see langword="null"/> or if <paramref name="tableName"/> is <see
|
||||
/// langword="null"/> or empty.</exception>
|
||||
public string GetTableCreateSql(IDbConnection cn, string tableName, string selectStatement = null) {
|
||||
if (cn == null) {
|
||||
throw new ArgumentNullException("cn");
|
||||
}
|
||||
@@ -36,49 +63,205 @@ namespace DbTools {
|
||||
if (cn.State != ConnectionState.Open) {
|
||||
cn.Open();
|
||||
}
|
||||
selectStatement = selectStatement.Replace("$table", tableName);
|
||||
using (IDbCommand cmd = cn.CreateCommand()) {
|
||||
cmd.CommandText = selectStatement;
|
||||
using (IDataReader reader = cmd.ExecuteReader(CommandBehavior.SchemaOnly | CommandBehavior.KeyInfo)) {
|
||||
DataTable schemaTable = reader.GetSchemaTable();
|
||||
if (schemaTable == null) {
|
||||
throw new Exception("Could not get schema for table " + tableName);
|
||||
}
|
||||
cmd.CommandText = $"select sql from sqlite_master where tbl_name='{tableName}' and type='table'";
|
||||
using (IDataReader reader = cmd.ExecuteReader()) {
|
||||
StringBuilder sb = new StringBuilder();
|
||||
sb.AppendLine("CREATE TABLE " + tableName + " (");
|
||||
List<string> pkColumns = new List<string>();
|
||||
foreach (DataRow row in schemaTable.Rows) {
|
||||
string columnName = row["ColumnName"].ToString();
|
||||
string dataType = row["DataTypeName"].ToString();
|
||||
int columnSize = Convert.ToInt32(row["ColumnSize"]);
|
||||
bool allowDBNull = Convert.ToBoolean(row["AllowDBNull"]);
|
||||
bool isKey = Convert.ToBoolean(row["IsKey"]);
|
||||
if (isKey) {
|
||||
pkColumns.Add(columnName);
|
||||
}
|
||||
sb.Append(" " + columnName + " " + dataType);
|
||||
if (dataType.Equals("VARCHAR", StringComparison.OrdinalIgnoreCase) ||
|
||||
dataType.Equals("CHAR", StringComparison.OrdinalIgnoreCase) ||
|
||||
dataType.Equals("NVARCHAR", StringComparison.OrdinalIgnoreCase) ||
|
||||
dataType.Equals("NCHAR", StringComparison.OrdinalIgnoreCase)) {
|
||||
sb.Append("(" + columnSize + ")");
|
||||
}
|
||||
if (!allowDBNull) {
|
||||
sb.Append(" NOT NULL");
|
||||
}
|
||||
sb.AppendLine(",");
|
||||
reader.Read();
|
||||
string sql = reader.GetString(0);
|
||||
|
||||
Match m = Regex.Match(sql, "CREATE TABLE \\S+ \\((.*)\\)", RegexOptions.Singleline);
|
||||
if (!m.Success) {
|
||||
Trace.TraceWarning("Unable to match regex on table " + tableName);
|
||||
return string.Empty;
|
||||
}
|
||||
if (pkColumns.Count > 0) {
|
||||
sb.AppendLine(" PRIMARY KEY (" + string.Join(", ", pkColumns) + ")");
|
||||
} else {
|
||||
// Remove the last comma
|
||||
sb.Length -= 3;
|
||||
|
||||
sb.AppendLine("-- TABLE " + tableName + " --");
|
||||
int startIndex = m.Groups[1].Index;
|
||||
int length = m.Groups[1].Length;
|
||||
string columns = Regex.Replace(m.Groups[1].Value, "\\s{2,}", " ");
|
||||
columns = Regex.Replace(columns.Replace(", ", ",").Replace(",\n", ","), ",(?!\\d+\\))", ",\r\n\t");
|
||||
|
||||
sb.AppendLine(sql.Substring(0, startIndex));
|
||||
sb.AppendLine("\t" + columns.Trim());
|
||||
sb.AppendLine(sql.Substring(startIndex + length) + ";");
|
||||
|
||||
string indexes = GetIndexCreateSql(cn, tableName);
|
||||
if (!string.IsNullOrEmpty(indexes)) {
|
||||
sb.AppendLine();
|
||||
sb.AppendLine("-- INDEXES --");
|
||||
sb.AppendLine(indexes);
|
||||
}
|
||||
sb.AppendLine(");");
|
||||
|
||||
string triggers = GetTriggerCreateSql(cn, tableName);
|
||||
if (!string.IsNullOrEmpty(triggers)) {
|
||||
sb.AppendLine();
|
||||
sb.AppendLine("-- TRIGGERS --");
|
||||
sb.AppendLine(triggers);
|
||||
}
|
||||
|
||||
if (!string.IsNullOrEmpty(selectStatement)) {
|
||||
string data = GetTableDataSql(cn, tableName, selectStatement);
|
||||
if (!string.IsNullOrEmpty(data)) {
|
||||
sb.AppendLine();
|
||||
sb.AppendLine("-- DATA --");
|
||||
sb.Append(data);
|
||||
}
|
||||
}
|
||||
sb.AppendLine("-- END TABLE " + tableName + " --");
|
||||
return sb.ToString();
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
/// <summary>
|
||||
/// Retrieves the SQL statements used to create all indexes for the specified table in a SQLite database.
|
||||
/// </summary>
|
||||
/// <remarks>This method queries the SQLite system table <c>sqlite_master</c> to retrieve the SQL
|
||||
/// definitions of indexes associated with the specified table. The connection must be open before executing the
|
||||
/// query; if it is not, the method will attempt to open it.</remarks>
|
||||
/// <param name="cn">The open database connection to use for the query. The connection must be to a SQLite database.</param>
|
||||
/// <param name="tableName">The name of the table whose index creation SQL statements are to be retrieved. Cannot be null or empty.</param>
|
||||
/// <returns>A string containing the SQL statements for creating all indexes on the specified table, separated by
|
||||
/// newlines. Returns an empty string if no indexes are found.</returns>
|
||||
/// <exception cref="ArgumentNullException">Thrown if <paramref name="cn"/> is null or if <paramref name="tableName"/> is null or empty.</exception>
|
||||
public string GetIndexCreateSql(IDbConnection cn, string tableName) {
|
||||
if (cn == null) {
|
||||
throw new ArgumentNullException("cn");
|
||||
}
|
||||
if (string.IsNullOrEmpty(tableName)) {
|
||||
throw new ArgumentNullException("tableName");
|
||||
}
|
||||
if (cn.State != ConnectionState.Open) {
|
||||
cn.Open();
|
||||
}
|
||||
using (IDbCommand cmd = cn.CreateCommand()) {
|
||||
cmd.CommandText = $"SELECT sql FROM sqlite_master WHERE type='index' AND tbl_name='{tableName}' AND sql NOT NULL;";
|
||||
StringBuilder sb = new StringBuilder();
|
||||
using (IDataReader reader = cmd.ExecuteReader()) {
|
||||
while (reader.Read()) {
|
||||
sb.AppendLine(reader.GetString(0) + ";");
|
||||
}
|
||||
}
|
||||
return sb.ToString();
|
||||
}
|
||||
}
|
||||
|
||||
/// <summary>
|
||||
/// Retrieves the SQL definition for all triggers associated with the specified table.
|
||||
/// </summary>
|
||||
/// <remarks>This method queries the SQLite system table `sqlite_master` to retrieve the SQL
|
||||
/// definitions of triggers. Ensure that the provided connection is valid and points to a SQLite
|
||||
/// database.</remarks>
|
||||
/// <param name="cn">An open database connection used to query the trigger definitions. The connection must be to a SQLite
|
||||
/// database.</param>
|
||||
/// <param name="tableName">The name of the table whose triggers are to be retrieved. Cannot be null or empty.</param>
|
||||
/// <returns>A string containing the SQL definitions of all triggers for the specified table, separated by semicolons.
|
||||
/// Returns an empty string if no triggers are found.</returns>
|
||||
/// <exception cref="ArgumentNullException">Thrown if <paramref name="cn"/> is null or if <paramref name="tableName"/> is null or empty.</exception>
|
||||
public string GetTriggerCreateSql(IDbConnection cn, string tableName) {
|
||||
if (cn == null) {
|
||||
throw new ArgumentNullException("cn");
|
||||
}
|
||||
if (string.IsNullOrEmpty(tableName)) {
|
||||
throw new ArgumentNullException("tableName");
|
||||
}
|
||||
if (cn.State != ConnectionState.Open) {
|
||||
cn.Open();
|
||||
}
|
||||
using (IDbCommand cmd = cn.CreateCommand()) {
|
||||
cmd.CommandText = $"SELECT sql FROM sqlite_master WHERE type='trigger' AND tbl_name='{tableName}' AND sql NOT NULL;";
|
||||
StringBuilder sb = new StringBuilder();
|
||||
using (IDataReader reader = cmd.ExecuteReader()) {
|
||||
while (reader.Read()) {
|
||||
sb.AppendLine(reader.GetString(0) + ";");
|
||||
}
|
||||
}
|
||||
return sb.ToString();
|
||||
}
|
||||
}
|
||||
|
||||
/// <summary>
|
||||
/// Generates an SQL script to insert data from a specified table into another database.
|
||||
/// </summary>
|
||||
/// <remarks>This method generates an SQL script that can be used to insert data into a table. The
|
||||
/// script is constructed based on the data retrieved by the provided SELECT statement. The method ensures that
|
||||
/// string and date values are properly escaped, and null values are represented as <c>NULL</c> in the
|
||||
/// script.</remarks>
|
||||
/// <param name="cn">An open <see cref="IDbConnection"/> used to execute the query. The connection must be open before calling
|
||||
/// this method.</param>
|
||||
/// <param name="tableName">The name of the table whose data will be used in the generated SQL script. Cannot be null or empty.</param>
|
||||
/// <param name="selectStatement">A SQL SELECT statement that retrieves the data to be included in the script. The placeholder <c>$table</c>
|
||||
/// in the statement will be replaced with the value of <paramref name="tableName"/>.</param>
|
||||
/// <returns>A string containing the generated SQL script. The script includes INSERT statements for the data retrieved
|
||||
/// by the <paramref name="selectStatement"/>.</returns>
|
||||
/// <exception cref="ArgumentNullException">Thrown if <paramref name="cn"/> is null or <paramref name="tableName"/> is null or empty.</exception>
|
||||
public string GetTableDataSql(IDbConnection cn, string tableName, string selectStatement) {
|
||||
if (cn == null) {
|
||||
throw new ArgumentNullException("cn");
|
||||
}
|
||||
|
||||
if (string.IsNullOrEmpty(tableName)) {
|
||||
throw new ArgumentNullException("tableName");
|
||||
}
|
||||
if (cn.State != ConnectionState.Open) {
|
||||
cn.Open();
|
||||
}
|
||||
|
||||
selectStatement = selectStatement.Replace("$table", tableName);
|
||||
using (IDbCommand cmd = cn.CreateCommand()) {
|
||||
cmd.CommandText = selectStatement;
|
||||
using (IDataReader reader = cmd.ExecuteReader()) {
|
||||
StringBuilder sb = new StringBuilder();
|
||||
int rowCount = 0;
|
||||
while (reader.Read()) {
|
||||
List<string> values = new List<string>();
|
||||
for (int i = 0; i < reader.FieldCount; i++) {
|
||||
object value = DBNull.Value;
|
||||
try {
|
||||
value = reader.GetValue(i);
|
||||
} catch { }
|
||||
if (value == DBNull.Value) {
|
||||
values.Add("NULL");
|
||||
} else if (value is string || value is DateTime) {
|
||||
values.Add("'" + value.ToString().Replace("'", "''") + "'");
|
||||
} else if (value is bool) {
|
||||
values.Add((bool)value ? "1" : "0");
|
||||
} else {
|
||||
values.Add(value.ToString());
|
||||
}
|
||||
}
|
||||
|
||||
if (rowCount % 100 == 0) {
|
||||
if (rowCount != 0)
|
||||
sb.AppendLine(";");
|
||||
sb.Append($"INSERT INTO {tableName} ({string.Join(", ", GetColumnNames(reader))}) VALUES");
|
||||
sb.AppendLine();
|
||||
sb.Append($" ({string.Join(", ", values)})");
|
||||
} else {
|
||||
sb.AppendLine(",");
|
||||
sb.Append($" ({string.Join(", ", values)})");
|
||||
}
|
||||
rowCount++;
|
||||
}
|
||||
if (rowCount > 0)
|
||||
sb.AppendLine(";");
|
||||
|
||||
return sb.ToString();
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
/// <summary>
|
||||
/// Retrieves the names of all columns from the specified <see cref="IDataReader"/>.
|
||||
/// </summary>
|
||||
/// <param name="reader">The <see cref="IDataReader"/> instance from which to retrieve column names. Must not be <see
|
||||
/// langword="null"/>.</param>
|
||||
/// <returns>An enumerable collection of strings representing the names of all columns in the data reader.</returns>
|
||||
private IEnumerable<string> GetColumnNames(IDataReader reader) {
|
||||
for (int i = 0; i < reader.FieldCount; i++) {
|
||||
yield return reader.GetName(i);
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
Reference in New Issue
Block a user