mirror of
https://github.com/nsnail/FreeSql.git
synced 2025-04-22 02:32:50 +08:00
- 增加 Oracle/达梦 批量更新 BulkCopy 扩展方法;
This commit is contained in:
parent
b0bac8efa7
commit
41ba6c37be
@ -1,4 +1,4 @@
|
|||||||
using FreeSql.DataAnnotations;
|
using FreeSql.DataAnnotations;
|
||||||
using System;
|
using System;
|
||||||
using System.Collections.Generic;
|
using System.Collections.Generic;
|
||||||
using System.Linq;
|
using System.Linq;
|
||||||
@ -235,13 +235,16 @@ INTO ""TB_TOPIC_INSERT""(""CLICKS"") VALUES(:Clicks_9)
|
|||||||
public void ExecuteOracleBulkCopy()
|
public void ExecuteOracleBulkCopy()
|
||||||
{
|
{
|
||||||
var items = new List<Topic_bulkcopy>();
|
var items = new List<Topic_bulkcopy>();
|
||||||
for (var a = 0; a < 10; a++) items.Add(new Topic_bulkcopy { Title = $"newtitle{a}", Clicks = a * 100, CreateTime = DateTime.Now });
|
for (var a = 0; a < 100; a++) items.Add(new Topic_bulkcopy { Title = $"newtitle{a}", Clicks = a * 100, CreateTime = DateTime.Now });
|
||||||
|
|
||||||
|
g.oracle.Delete<Topic_bulkcopy>().Where("1=1").ExecuteAffrows();
|
||||||
g.oracle.Insert<Topic_bulkcopy>().AppendData(items).InsertIdentity().ExecuteOracleBulkCopy();
|
g.oracle.Insert<Topic_bulkcopy>().AppendData(items).InsertIdentity().ExecuteOracleBulkCopy();
|
||||||
//insert.AppendData(items).IgnoreColumns(a => new { a.CreateTime, a.Clicks }).ExecuteSqlBulkCopy();
|
//insert.AppendData(items).IgnoreColumns(a => new { a.CreateTime, a.Clicks }).ExecuteSqlBulkCopy();
|
||||||
// System.NotSupportedException:“DataSet does not support System.Nullable<>.”
|
// System.NotSupportedException:“DataSet does not support System.Nullable<>.”
|
||||||
|
|
||||||
|
g.oracle.Update<Topic_bulkcopy>().SetSource(items).ExecuteOracleBulkCopy();
|
||||||
}
|
}
|
||||||
[Table(Name = "tb_topic_bulkcopy")]
|
[Table(Name = "tb_topic_bk1")]
|
||||||
class Topic_bulkcopy
|
class Topic_bulkcopy
|
||||||
{
|
{
|
||||||
public Guid Id { get; set; }
|
public Guid Id { get; set; }
|
||||||
|
@ -71,6 +71,15 @@ namespace FreeSql.Internal.CommonProvider
|
|||||||
.AsTable(state.Item4);
|
.AsTable(state.Item4);
|
||||||
(insert as InsertProvider)._isAutoSyncStructure = false;
|
(insert as InsertProvider)._isAutoSyncStructure = false;
|
||||||
funcBulkCopy(insert);
|
funcBulkCopy(insert);
|
||||||
|
switch (fsql.Ado.DataType)
|
||||||
|
{
|
||||||
|
case DataType.Oracle:
|
||||||
|
case DataType.OdbcOracle:
|
||||||
|
case DataType.CustomOracle:
|
||||||
|
case DataType.Dameng:
|
||||||
|
case DataType.OdbcDameng:
|
||||||
|
return fsql.Ado.CommandFluent(state.Item2).WithConnection(connection).WithTransaction(transaction).ExecuteNonQuery();
|
||||||
|
}
|
||||||
var affrows = fsql.Ado.CommandFluent(state.Item2 + ";\r\n" + state.Item3).WithConnection(connection).WithTransaction(transaction).ExecuteNonQuery();
|
var affrows = fsql.Ado.CommandFluent(state.Item2 + ";\r\n" + state.Item3).WithConnection(connection).WithTransaction(transaction).ExecuteNonQuery();
|
||||||
droped = true;
|
droped = true;
|
||||||
return affrows;
|
return affrows;
|
||||||
|
@ -1,6 +1,11 @@
|
|||||||
using Dm;
|
using Dm;
|
||||||
using FreeSql;
|
using FreeSql;
|
||||||
|
using FreeSql.Internal.CommonProvider;
|
||||||
|
using FreeSql.Internal.Model;
|
||||||
using System;
|
using System;
|
||||||
|
using System.Collections.Generic;
|
||||||
|
using System.Linq;
|
||||||
|
using System.Text;
|
||||||
|
|
||||||
public static partial class FreeSqlDamengGlobalExtensions
|
public static partial class FreeSqlDamengGlobalExtensions
|
||||||
{
|
{
|
||||||
@ -15,6 +20,58 @@ public static partial class FreeSqlDamengGlobalExtensions
|
|||||||
static FreeSql.Dameng.DamengAdo _damengAdo = new FreeSql.Dameng.DamengAdo();
|
static FreeSql.Dameng.DamengAdo _damengAdo = new FreeSql.Dameng.DamengAdo();
|
||||||
|
|
||||||
#region ExecuteDmBulkCopy
|
#region ExecuteDmBulkCopy
|
||||||
|
|
||||||
|
/// <summary>
|
||||||
|
/// 批量更新(更新字段数量超过 2000 时收益大)<para></para>
|
||||||
|
/// 实现原理:使用 OracleBulkCopy 插入临时表,再使用 MERGE INTO 联表更新
|
||||||
|
/// </summary>
|
||||||
|
/// <typeparam name="T"></typeparam>
|
||||||
|
/// <param name="that"></param>
|
||||||
|
/// <returns></returns>
|
||||||
|
public static int ExecuteDmBulkCopy<T>(this IUpdate<T> that) where T : class
|
||||||
|
{
|
||||||
|
var update = that as UpdateProvider<T>;
|
||||||
|
if (update._source.Any() != true || update._tempPrimarys.Any() == false) return 0;
|
||||||
|
var state = ExecuteDmBulkCopyState(update);
|
||||||
|
return UpdateProvider.ExecuteBulkUpdate(update, state, insert => insert.ExecuteDmBulkCopy());
|
||||||
|
}
|
||||||
|
static NativeTuple<string, string, string, string, string[]> ExecuteDmBulkCopyState<T>(UpdateProvider<T> update) where T : class
|
||||||
|
{
|
||||||
|
if (update._source.Any() != true) return null;
|
||||||
|
var _table = update._table;
|
||||||
|
var _commonUtils = update._commonUtils;
|
||||||
|
var updateTableName = update._tableRule?.Invoke(_table.DbName) ?? _table.DbName;
|
||||||
|
var tempTableName = $"Temp_{Guid.NewGuid().ToString("N").ToUpper().Substring(0, 24)}";
|
||||||
|
if (update._orm.CodeFirst.IsSyncStructureToLower) tempTableName = tempTableName.ToLower();
|
||||||
|
if (update._orm.CodeFirst.IsSyncStructureToUpper) tempTableName = tempTableName.ToUpper();
|
||||||
|
if (update._connection == null && update._orm.Ado.TransactionCurrentThread != null)
|
||||||
|
update.WithTransaction(update._orm.Ado.TransactionCurrentThread);
|
||||||
|
var sb = new StringBuilder().Append("CREATE GLOBAL TEMPORARY TABLE ").Append(_commonUtils.QuoteSqlName(tempTableName)).Append(" ( ");
|
||||||
|
var setColumns = new List<string>();
|
||||||
|
var pkColumns = new List<string>();
|
||||||
|
foreach (var col in _table.Columns.Values)
|
||||||
|
{
|
||||||
|
if (update._tempPrimarys.Any(a => a.CsName == col.CsName)) pkColumns.Add(col.Attribute.Name);
|
||||||
|
else if (col.Attribute.IsIdentity == false && col.Attribute.IsVersion == false && update._ignore.ContainsKey(col.Attribute.Name) == false) setColumns.Add(col.Attribute.Name);
|
||||||
|
else continue;
|
||||||
|
sb.Append(" \r\n ").Append(_commonUtils.QuoteSqlName(col.Attribute.Name)).Append(" ").Append(col.Attribute.DbType.Replace("NOT NULL", ""));
|
||||||
|
sb.Append(",");
|
||||||
|
}
|
||||||
|
var sql1 = sb.Remove(sb.Length - 1, 1).Append("\r\n) ON COMMIT PRESERVE ROWS").ToString();
|
||||||
|
|
||||||
|
sb.Clear().Append("MERGE INTO ").Append(_commonUtils.QuoteSqlName(updateTableName)).Append(" a ")
|
||||||
|
.Append(" \r\nUSING ").Append(_commonUtils.QuoteSqlName(tempTableName)).Append(" b ON (").Append(string.Join(" AND ", pkColumns.Select(col => $"a.{_commonUtils.QuoteSqlName(col)} = b.{_commonUtils.QuoteSqlName(col)}")))
|
||||||
|
.Append(") \r\nWHEN MATCHED THEN")
|
||||||
|
.Append(" \r\nUPDATE SET ").Append(string.Join(", \r\n ", setColumns.Select(col => $"{_commonUtils.QuoteSqlName(col)} = b.{_commonUtils.QuoteSqlName(col)}")));
|
||||||
|
var sql2 = sb.ToString();
|
||||||
|
sb.Clear();
|
||||||
|
var sql3 = $"BEGIN \r\n" +
|
||||||
|
$"execute immediate 'TRUNCATE TABLE {_commonUtils.QuoteSqlName(tempTableName)}';\r\n" +
|
||||||
|
$"execute immediate 'DROP TABLE {_commonUtils.QuoteSqlName(tempTableName)}';\r\n" +
|
||||||
|
$"END;";
|
||||||
|
return NativeTuple.Create(sql1, sql2, sql3, tempTableName, pkColumns.Concat(setColumns).ToArray());
|
||||||
|
}
|
||||||
|
|
||||||
/// <summary>
|
/// <summary>
|
||||||
/// 达梦 CopyBulk 批量插入功能<para></para>
|
/// 达梦 CopyBulk 批量插入功能<para></para>
|
||||||
/// 使用 IgnoreColumns/InsertColumns 设置忽略/指定导入的列<para></para>
|
/// 使用 IgnoreColumns/InsertColumns 设置忽略/指定导入的列<para></para>
|
||||||
|
@ -1,10 +1,15 @@
|
|||||||
using FreeSql;
|
using FreeSql;
|
||||||
|
using FreeSql.Internal.CommonProvider;
|
||||||
|
using FreeSql.Internal.Model;
|
||||||
#if oledb
|
#if oledb
|
||||||
using System.Data.OleDb;
|
using System.Data.OleDb;
|
||||||
#else
|
#else
|
||||||
using Oracle.ManagedDataAccess.Client;
|
using Oracle.ManagedDataAccess.Client;
|
||||||
#endif
|
#endif
|
||||||
using System;
|
using System;
|
||||||
|
using System.Collections.Generic;
|
||||||
|
using System.Linq;
|
||||||
|
using System.Text;
|
||||||
|
|
||||||
public static partial class FreeSqlOracleGlobalExtensions
|
public static partial class FreeSqlOracleGlobalExtensions
|
||||||
{
|
{
|
||||||
@ -21,6 +26,57 @@ public static partial class FreeSqlOracleGlobalExtensions
|
|||||||
#if oledb
|
#if oledb
|
||||||
#else
|
#else
|
||||||
#region ExecuteOracleBulkCopy
|
#region ExecuteOracleBulkCopy
|
||||||
|
/// <summary>
|
||||||
|
/// 批量更新(更新字段数量超过 2000 时收益大)<para></para>
|
||||||
|
/// 实现原理:使用 OracleBulkCopy 插入临时表,再使用 MERGE INTO 联表更新
|
||||||
|
/// </summary>
|
||||||
|
/// <typeparam name="T"></typeparam>
|
||||||
|
/// <param name="that"></param>
|
||||||
|
/// <returns></returns>
|
||||||
|
public static int ExecuteOracleBulkCopy<T>(this IUpdate<T> that) where T : class
|
||||||
|
{
|
||||||
|
var update = that as UpdateProvider<T>;
|
||||||
|
if (update._source.Any() != true || update._tempPrimarys.Any() == false) return 0;
|
||||||
|
var state = ExecuteOracleBulkCopyState(update);
|
||||||
|
return UpdateProvider.ExecuteBulkUpdate(update, state, insert => insert.ExecuteOracleBulkCopy());
|
||||||
|
}
|
||||||
|
static NativeTuple<string, string, string, string, string[]> ExecuteOracleBulkCopyState<T>(UpdateProvider<T> update) where T : class
|
||||||
|
{
|
||||||
|
if (update._source.Any() != true) return null;
|
||||||
|
var _table = update._table;
|
||||||
|
var _commonUtils = update._commonUtils;
|
||||||
|
var updateTableName = update._tableRule?.Invoke(_table.DbName) ?? _table.DbName;
|
||||||
|
var tempTableName = $"Temp_{Guid.NewGuid().ToString("N").ToUpper().Substring(0, 24)}";
|
||||||
|
if (update._orm.CodeFirst.IsSyncStructureToLower) tempTableName = tempTableName.ToLower();
|
||||||
|
if (update._orm.CodeFirst.IsSyncStructureToUpper) tempTableName = tempTableName.ToUpper();
|
||||||
|
if (update._connection == null && update._orm.Ado.TransactionCurrentThread != null)
|
||||||
|
update.WithTransaction(update._orm.Ado.TransactionCurrentThread);
|
||||||
|
var sb = new StringBuilder().Append("CREATE GLOBAL TEMPORARY TABLE ").Append(_commonUtils.QuoteSqlName(tempTableName)).Append(" ( ");
|
||||||
|
var setColumns = new List<string>();
|
||||||
|
var pkColumns = new List<string>();
|
||||||
|
foreach (var col in _table.Columns.Values)
|
||||||
|
{
|
||||||
|
if (update._tempPrimarys.Any(a => a.CsName == col.CsName)) pkColumns.Add(col.Attribute.Name);
|
||||||
|
else if (col.Attribute.IsIdentity == false && col.Attribute.IsVersion == false && update._ignore.ContainsKey(col.Attribute.Name) == false) setColumns.Add(col.Attribute.Name);
|
||||||
|
else continue;
|
||||||
|
sb.Append(" \r\n ").Append(_commonUtils.QuoteSqlName(col.Attribute.Name)).Append(" ").Append(col.Attribute.DbType.Replace("NOT NULL", ""));
|
||||||
|
sb.Append(",");
|
||||||
|
}
|
||||||
|
var sql1 = sb.Remove(sb.Length - 1, 1).Append("\r\n) ON COMMIT PRESERVE ROWS").ToString();
|
||||||
|
|
||||||
|
sb.Clear().Append("MERGE INTO ").Append(_commonUtils.QuoteSqlName(updateTableName)).Append(" a ")
|
||||||
|
.Append(" \r\nUSING ").Append(_commonUtils.QuoteSqlName(tempTableName)).Append(" b ON (").Append(string.Join(" AND ", pkColumns.Select(col => $"a.{_commonUtils.QuoteSqlName(col)} = b.{_commonUtils.QuoteSqlName(col)}")))
|
||||||
|
.Append(") \r\nWHEN MATCHED THEN")
|
||||||
|
.Append(" \r\nUPDATE SET ").Append(string.Join(", \r\n ", setColumns.Select(col => $"{_commonUtils.QuoteSqlName(col)} = b.{_commonUtils.QuoteSqlName(col)}")));
|
||||||
|
var sql2 = sb.ToString();
|
||||||
|
sb.Clear();
|
||||||
|
var sql3 = $"BEGIN \r\n" +
|
||||||
|
$"execute immediate 'TRUNCATE TABLE {_commonUtils.QuoteSqlName(tempTableName)}';\r\n" +
|
||||||
|
$"execute immediate 'DROP TABLE {_commonUtils.QuoteSqlName(tempTableName)}';\r\n" +
|
||||||
|
$"END;";
|
||||||
|
return NativeTuple.Create(sql1, sql2, sql3, tempTableName, pkColumns.Concat(setColumns).ToArray());
|
||||||
|
}
|
||||||
|
|
||||||
/// <summary>
|
/// <summary>
|
||||||
/// Oracle CopyBulk 批量插入功能<para></para>
|
/// Oracle CopyBulk 批量插入功能<para></para>
|
||||||
/// 使用 IgnoreColumns/InsertColumns 设置忽略/指定导入的列<para></para>
|
/// 使用 IgnoreColumns/InsertColumns 设置忽略/指定导入的列<para></para>
|
||||||
|
Loading…
x
Reference in New Issue
Block a user