Skip to content

Commit

Permalink
- Added support to load Table Schema for Temp Tables (basic Schema de…
Browse files Browse the repository at this point in the history
…tails needed for BulkInsert or Update, etc. to allow Bulk Loading Temp Tables!

- Improved Error message for when custom SQL Merge Match qualifiers are specified but DB Schema may have changed making them invalid or missing from Cached schema.
  • Loading branch information
cajuncoding committed Oct 24, 2023
1 parent cac2c35 commit 21916f8
Show file tree
Hide file tree
Showing 8 changed files with 102 additions and 12 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -58,6 +58,17 @@ protected string GetTableSchemaSqlQuery(TableSchemaDetailLevel detailLevel)
)
{
var tableSchemaQuerySql = GetTableSchemaSqlQuery(detailLevel);

//Enable Support for Temp Table Schema Loading...
if (tableNameTerm.IsTempTableName)
{
//NOTE: For Temp Table support all references to INFORMATION_SCHEMA must be replaced with tempdb.INFORMATION_SCHEMA
// and DB_NAME() must be changed to 'tempdb', otherwise we dynamically resolve the true Temp Table Name in the Cte...
tableSchemaQuerySql = tableSchemaQuerySql
.Replace("INFORMATION_SCHEMA.", "tempdb.INFORMATION_SCHEMA.")
.Replace("DB_NAME()", "'tempdb'");
}

var sqlCmd = new SqlCommand(tableSchemaQuerySql, sqlConnection, sqlTransaction);

//Configure the timeout for retrieving the Schema details...
Expand All @@ -67,6 +78,7 @@ protected string GetTableSchemaSqlQuery(TableSchemaDetailLevel detailLevel)
var sqlParams = sqlCmd.Parameters;
sqlParams.Add(new SqlParameter("@TableSchema", tableNameTerm.SchemaName));
sqlParams.Add(new SqlParameter("@TableName", tableNameTerm.TableName));
sqlParams.Add(new SqlParameter("@IsTempTable", tableNameTerm.IsTempTableName));
return sqlCmd;
}

Expand Down Expand Up @@ -131,7 +143,8 @@ protected string GetTableSchemaSqlQuery(TableSchemaDetailLevel detailLevel)
var tableNameTerm = tableName.ParseAsTableNameTerm();
var cacheKey = CreateCacheKeyInternal(tableNameTerm, detailLevel);

if (forceCacheReload)
//NOTE: We also prevent caching of Temp Table schemas that are by definition Transient!
if (forceCacheReload || tableNameTerm.IsTempTableName)
TableDefinitionsCaseInsensitiveLazyCache.TryRemoveAsyncValue(cacheKey);

var tableDefinition = await TableDefinitionsCaseInsensitiveLazyCache.GetOrAddAsync(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -75,7 +75,8 @@ public partial class SqlBulkHelpersDBSchemaLoader : ISqlBulkHelpersDBSchemaLoade
var tableNameTerm = tableName.ParseAsTableNameTerm();
var cacheKey = CreateCacheKeyInternal(tableNameTerm, detailLevel);

if (forceCacheReload)
//NOTE: We also prevent caching of Temp Table schemas that are by definition Transient!
if (forceCacheReload || tableNameTerm.IsTempTableName)
TableDefinitionsCaseInsensitiveLazyCache.TryRemove(cacheKey);

var tableDefinitionResult = TableDefinitionsCaseInsensitiveLazyCache.GetOrAdd(
Expand Down
Original file line number Diff line number Diff line change
@@ -1,14 +1,19 @@
WITH TablesCte AS (
--NOTE: For Temp Table support all references to INFORMATION_SCHEMA must be replaced with tempdb.INFORMATION_SCHEMA
-- and DB_NAME() must be changed to 'tempdb', otherwise we dynamically resolve the true Temp Table Name in the Cte...
WITH TablesCte AS (
SELECT TOP (1)
TableSchema = t.[TABLE_SCHEMA],
TableName = t.[TABLE_NAME],
TableCatalog = t.[TABLE_CATALOG],
ObjectId = OBJECT_ID('['+t.TABLE_SCHEMA+'].['+t.TABLE_NAME+']')
ObjectId = OBJECT_ID(CONCAT('[', t.TABLE_CATALOG, '].[', t.TABLE_SCHEMA, '].[', t.TABLE_NAME, ']'))
FROM INFORMATION_SCHEMA.TABLES t
WHERE
t.TABLE_SCHEMA = @TableSchema
AND t.TABLE_NAME = @TableName
AND t.TABLE_CATALOG = DB_NAME()
AND t.TABLE_NAME = CASE
WHEN @IsTempTable = 0 THEN @TableName
ELSE (SELECT TOP (1) t.[name] FROM tempdb.sys.objects t WHERE t.[object_id] = OBJECT_ID(CONCAT(N'tempdb.[', @TableSchema, '].[', @TableName, ']')))
END
)
SELECT
t.TableSchema,
Expand Down
Original file line number Diff line number Diff line change
@@ -1,14 +1,19 @@
WITH TablesCte AS (
--NOTE: For Temp Table support all references to INFORMATION_SCHEMA must be replaced with tempdb.INFORMATION_SCHEMA
-- and DB_NAME() must be changed to 'tempdb', otherwise we dynamically resolve the true Temp Table Name in the Cte...
WITH TablesCte AS (
SELECT TOP (1)
TableSchema = t.[TABLE_SCHEMA],
TableName = t.[TABLE_NAME],
TableCatalog = t.[TABLE_CATALOG],
ObjectId = OBJECT_ID('['+t.TABLE_SCHEMA+'].['+t.TABLE_NAME+']')
ObjectId = OBJECT_ID(CONCAT('[', t.TABLE_CATALOG, '].[', t.TABLE_SCHEMA, '].[', t.TABLE_NAME, ']'))
FROM INFORMATION_SCHEMA.TABLES t
WHERE
t.TABLE_SCHEMA = @TableSchema
AND t.TABLE_NAME = @TableName
AND t.TABLE_CATALOG = DB_NAME()
AND t.TABLE_NAME = CASE
WHEN @IsTempTable = 0 THEN @TableName
ELSE (SELECT TOP (1) t.[name] FROM tempdb.sys.objects t WHERE t.[object_id] = OBJECT_ID(CONCAT(N'tempdb.[', @TableSchema, '].[', @TableName, ']')))
END
)
SELECT
t.TableSchema,
Expand Down
1 change: 1 addition & 0 deletions NetStandard.SqlBulkHelpers/Database/TableNameTerm.cs
Original file line number Diff line number Diff line change
Expand Up @@ -21,6 +21,7 @@ public TableNameTerm(string schemaName, string tableName)
public string TableName { get; }
public string TableNameVariable { get; }
public string FullyQualifiedTableName { get; }
public bool IsTempTableName => TableName.StartsWith("#");

public override string ToString() => FullyQualifiedTableName;

Expand Down
9 changes: 5 additions & 4 deletions NetStandard.SqlBulkHelpers/NetStandard.SqlBulkHelpers.csproj
Original file line number Diff line number Diff line change
Expand Up @@ -8,17 +8,18 @@
<PackageLicenseExpression>MIT</PackageLicenseExpression>
<Authors>BBernard / CajunCoding</Authors>
<Company>CajunCoding</Company>
<Version>2.4.0</Version>
<Version>2.4.1</Version>
<PackageProjectUrl>https://github.com/cajuncoding/SqlBulkHelpers</PackageProjectUrl>
<RepositoryUrl>https://github.com/cajuncoding/SqlBulkHelpers</RepositoryUrl>
<Description>A library for easy, efficient and high performance bulk insert and update of data, into a Sql Database, from .Net applications. By leveraging the power of the SqlBulkCopy classes with added support for Identity primary key table columns this library provides a greatly simplified interface to process Identity based Entities with Bulk Performance with the wide compatibility of .NetStandard 2.0.</Description>
<PackageTags>sql server database table bulk insert update identity column sqlbulkcopy orm dapper linq2sql materialization materialized data view materialized-data materialized-view sync replication replica readonly</PackageTags>
<PackageReleaseNotes>
-Added new explicit CopyTableDataAsync() APIs which enable explicit copying of data between two tables on matching columns (automatically detected by column Name and Data Type).
-Added new Materialized Data Configuration value MaterializedDataLoadingTableDataCopyMode to control whether the materialized data process automatically copies data into the Loading Tables after cloning.
This helps to greatly simplify new use cases where data must be merged (and preserved) during the materialization process.
- Added support to load Table Schema for Temp Tables (basic Schema details needed for BulkInsert or Update, etc. to allow Bulk Loading Temp Tables!
- Improved Error message for when custom SQL Merge Match qualifiers are specified but DB Schema may have changed making them invalid or missing from Cached schema.

Prior Relese Notes:
-Added new explicit CopyTableDataAsync() APIs which enable explicit copying of data between two tables on matching columns (automatically detected by column Name and Data Type).
-Added new Materialized Data Configuration value MaterializedDataLoadingTableDataCopyMode to control whether the materialized data process automatically copies data into the Loading Tables after cloning. This helps to greatly simplify new use cases where data must be merged (and preserved) during the materialization process.
- Fixed bug with Sql Bulk Insert/Update processing with Model Properties that have mapped database names via mapping attribute (e.g. [SqlBulkColumn("")], [Map("")], [Column("")], etc.).
- Changed default behaviour to no longer clone tables/schema inside a Transaction which creates a full Schema Lock -- as this greatly impacts Schema aware ORMs such as SqlBulkHelpers, RepoDb, etc.
- New separate methods is now added to handle the CleanupMaterializeDataProcessAsync() but must be explicitly called as it is no longer implicitly called with FinishMaterializeDataProcessAsync().
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -52,6 +52,12 @@ public class SqlBulkHelpersMergeScriptBuilder
}
}

if (sanitizedQualifierFields.IsNullOrEmpty())
throw new ArgumentException($"The merge match qualifier fields specified [{matchQualifierExpression.MatchQualifierFields.Select(f => f.Name).ToCsv()}] " +
$"are invalid and could not be resolved to valid fields on the target table {tableDefinition.TableFullyQualifiedName}. " +
$"This could be the result of an invalid argument or potentially due to database schema changes that are not reflected in the schema cache; " +
$"you may try bypassing the cache via the bool forceCacheReload parameter or the static SqlBulkHelpersSchemaLoaderCache.ClearCache() method.");

//If we have valid Fields, then we must re-initialize a valid Qualifier Expression parameter with ONLY the valid fields...
sanitizedQualifierExpression = new SqlMergeMatchQualifierExpression(sanitizedQualifierFields)
{
Expand Down
Original file line number Diff line number Diff line change
@@ -1,6 +1,8 @@
using System;
using System.Diagnostics;
using Microsoft.Data.SqlClient;
using RepoDb;
using SqlBulkHelpers.CustomExtensions;
using SqlBulkHelpers.SqlBulkHelpers;

namespace SqlBulkHelpers.Tests.IntegrationTests
Expand All @@ -22,6 +24,25 @@ public void TestTableDefinitionLoadingBasicDetailsWithTransactionSyncMethod()
AssertTableDefinitionIsValidForTestElementParentTable(tableDefinition, TableSchemaDetailLevel.BasicDetails);
}

[TestMethod]
public void TestTableDefinitionLoadingBasicDetailsForTempTableWithTransactionSyncMethod()
{
using var sqlConn = SqlConnectionHelper.NewConnection();
using var sqlTransaction = sqlConn.BeginTransaction();

var tempTableName = "#TempTableSchemaLoaderTest";
sqlConn.ExecuteNonQuery($@"
CREATE TABLE [{tempTableName}] ([Id] INT NOT NULL PRIMARY KEY);
", transaction: sqlTransaction);

var tableDefinition = sqlTransaction.GetTableSchemaDefinition(
tempTableName,
TableSchemaDetailLevel.BasicDetails
);

AssertTableDefinitionIsValidForTempTable(tempTableName, tableDefinition);
}

[TestMethod]
public void TestTableDefinitionLoadingExtendedDetailsSyncMethods()
{
Expand Down Expand Up @@ -49,6 +70,27 @@ public async Task TestTableDefinitionLoadingBasicDetailsWithTransactionAsync()
AssertTableDefinitionIsValidForTestElementParentTable(tableDefinition, TableSchemaDetailLevel.BasicDetails);
}

[TestMethod]
public async Task TestTableDefinitionLoadingBasicDetailsForTempTableWithTransactionAsync()
{
var sqlConnectionProvider = SqlConnectionHelper.GetConnectionProvider();
await using var sqlConn = await sqlConnectionProvider.NewConnectionAsync().ConfigureAwait(false);
await using var sqlTransaction = (SqlTransaction)await sqlConn.BeginTransactionAsync();

var tempTableName = "#TempTableSchemaLoaderTest";
await sqlConn.ExecuteNonQueryAsync($@"
CREATE TABLE [{tempTableName}] ([Id] INT NOT NULL PRIMARY KEY);
", transaction: sqlTransaction);

var tableDefinition = await sqlTransaction.GetTableSchemaDefinitionAsync(
tempTableName,
TableSchemaDetailLevel.BasicDetails
).ConfigureAwait(false);

AssertTableDefinitionIsValidForTempTable(tempTableName, tableDefinition);
}


[TestMethod]
public async Task TestTableDefinitionLoadingExtendedDetailsAsync()
{
Expand Down Expand Up @@ -85,6 +127,22 @@ private void AssertTableDefinitionIsValidForTestElementParentTable(SqlBulkHelper
}
}

private void AssertTableDefinitionIsValidForTempTable(string tempTableName, SqlBulkHelpersTableDefinition tableDefinition)
{
Assert.IsNotNull(tableDefinition);

var tableNameTerm = TableNameTerm.From(tempTableName);
Assert.IsTrue(tableNameTerm.IsTempTableName);
Assert.AreEqual(TableSchemaDetailLevel.BasicDetails, tableDefinition.SchemaDetailLevel);
Assert.AreEqual(tableNameTerm.SchemaName, tableDefinition.TableSchema);
//NOTE: Table Names will not match exactly due to internal Hashing of the Temp Name for Session isolation, etc...
//Assert.AreEqual(tableNameTerm.TableName, tableDefinition.TableName);
//Assert.AreEqual(tableNameTerm.FullyQualifiedTableName, tableDefinition.TableFullyQualifiedName);
Assert.AreEqual(1, tableDefinition.TableColumns.Count);
Assert.IsNotNull(tableDefinition.PrimaryKeyConstraint);
Assert.AreEqual(0, tableDefinition.ForeignKeyConstraints.Count);
}

[TestMethod]
public void TestTableDefinitionLoadingAndCachingSyncMethods()
{
Expand Down

0 comments on commit 21916f8

Please sign in to comment.