From 002b07b27341fd679194574e88b14c14a299fecb Mon Sep 17 00:00:00 2001 From: Paul Guyot Date: Thu, 30 Mar 2023 14:06:11 +0200 Subject: [PATCH] Add procedure ResultSetInsert The ResultSetInsert procedure works like ResultSetFilter but insert results into a table which name is passed as third paramter, `@Table`. This works around the nested insert exec issue (#18). This is an alternative and original implementation of PR #19. Signed-off-by: Paul Guyot --- Source/tSQLtCLR_CreateProcs.sql | 6 ++ Tests/ResultSetInsertTests.class.sql | 117 ++++++++++++++++++++++++ Tests/Tests.ssmssqlproj | 6 ++ tSQLtCLR/tSQLtCLR/ResultSetFilter.cs | 40 ++++++++ tSQLtCLR/tSQLtCLR/StoredProcedures.cs | 5 + tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs | 23 +++++ 6 files changed, 197 insertions(+) create mode 100644 Tests/ResultSetInsertTests.class.sql diff --git a/Source/tSQLtCLR_CreateProcs.sql b/Source/tSQLtCLR_CreateProcs.sql index 14aed3ff4..f4c56a97f 100644 --- a/Source/tSQLtCLR_CreateProcs.sql +++ b/Source/tSQLtCLR_CreateProcs.sql @@ -14,6 +14,7 @@ limitations under the License. */ IF OBJECT_ID('tSQLt.ResultSetFilter') IS NOT NULL DROP PROCEDURE tSQLt.ResultSetFilter; +IF OBJECT_ID('tSQLt.ResultSetInsert') IS NOT NULL DROP PROCEDURE tSQLt.ResultSetInsert; IF OBJECT_ID('tSQLt.AssertResultSetsHaveSameMetaData') IS NOT NULL DROP PROCEDURE tSQLt.AssertResultSetsHaveSameMetaData; IF OBJECT_ID('tSQLt.NewConnection') IS NOT NULL DROP PROCEDURE tSQLt.NewConnection; IF OBJECT_ID('tSQLt.CaptureOutput') IS NOT NULL DROP PROCEDURE tSQLt.CaptureOutput; @@ -32,6 +33,11 @@ AS EXTERNAL NAME tSQLtCLR.[tSQLtCLR.StoredProcedures].ResultSetFilter; GO +CREATE PROCEDURE tSQLt.ResultSetInsert @ResultsetNo INT, @Command NVARCHAR(MAX), @Table NVARCHAR(MAX) +AS +EXTERNAL NAME tSQLtCLR.[tSQLtCLR.StoredProcedures].ResultSetInsert; +GO + CREATE PROCEDURE tSQLt.AssertResultSetsHaveSameMetaData @expectedCommand NVARCHAR(MAX), @actualCommand NVARCHAR(MAX) AS EXTERNAL NAME tSQLtCLR.[tSQLtCLR.StoredProcedures].AssertResultSetsHaveSameMetaData; diff --git a/Tests/ResultSetInsertTests.class.sql b/Tests/ResultSetInsertTests.class.sql new file mode 100644 index 000000000..dbca0ec5c --- /dev/null +++ b/Tests/ResultSetInsertTests.class.sql @@ -0,0 +1,117 @@ +EXEC tSQLt.NewTestClass 'ResultSetInsertTests'; +GO +CREATE PROC ResultSetInsertTests.[test ResultSetInsert returns specified result set] +AS +BEGIN + CREATE TABLE #Actual (val INT); + + EXEC tSQLt.ResultSetInsert 3, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val UNION ALL SELECT 4 UNION ALL SELECT 5;', '#Actual'; + + CREATE TABLE #Expected (val INT); + INSERT INTO #Expected + SELECT 3 AS val UNION ALL SELECT 4 UNION ALL SELECT 5; + + EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected'; +END; +GO + +CREATE PROC ResultSetInsertTests.[test ResultSetInsert returns specified result set with multiple columns] +AS +BEGIN + CREATE TABLE #Actual (val1 INT, val2 VARCHAR(3)); + + EXEC tSQLt.ResultSetInsert 2, 'SELECT 1 AS val; SELECT 3 AS val1, ''ABC'' AS val2 UNION ALL SELECT 4, ''DEF'' UNION ALL SELECT 5, ''GHI''; SELECT 2 AS val;', '#Actual'; + + CREATE TABLE #Expected (val1 INT, val2 VARCHAR(3)); + INSERT INTO #Expected + SELECT 3 AS val1, 'ABC' AS val2 UNION ALL SELECT 4, 'DEF' UNION ALL SELECT 5, 'GHI'; + + EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected'; +END; +GO + +CREATE PROC ResultSetInsertTests.[test ResultSetInsert throws error if specified result set is 1 greater than number of result sets returned] +AS +BEGIN + DECLARE @err NVARCHAR(MAX); SET @err = '--NO Error Thrown!--'; + + CREATE TABLE #Actual (val INT); + + BEGIN TRY + EXEC tSQLt.ResultSetInsert 4, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val;', '#Actual'; + END TRY + BEGIN CATCH + SET @err = ERROR_MESSAGE(); + END CATCH + + IF @err NOT LIKE '%Execution returned only 3 ResultSets. ResultSet [[]4] does not exist.%' + BEGIN + EXEC tSQLt.Fail 'Unexpected error message was: ', @err; + END; +END; +GO + +CREATE PROC ResultSetInsertTests.[test ResultSetFilter throws error if specified result set is more than 1 greater than number of result sets returned] +AS +BEGIN + DECLARE @err NVARCHAR(MAX); SET @err = '--NO Error Thrown!--'; + + CREATE TABLE #Actual (val INT); + + BEGIN TRY + EXEC tSQLt.ResultSetInsert 9, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val; SELECT 4 AS val; SELECT 5 AS val;', '#Actual'; + END TRY + BEGIN CATCH + SET @err = ERROR_MESSAGE(); + END CATCH + + IF @err NOT LIKE '%Execution returned only 5 ResultSets. ResultSet [[]9] does not exist.%' + BEGIN + EXEC tSQLt.Fail 'Unexpected error message was: ', @err; + END; +END; +GO + +CREATE PROC ResultSetInsertTests.[test ResultSetFilter retrieves no records and throws no error if 0 is specified] +AS +BEGIN + CREATE TABLE #Actual (val INT); + + EXEC tSQLt.ResultSetInsert 0, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val;', '#Actual'; + + CREATE TABLE #Expected (val INT); + + EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected'; +END; +GO + +CREATE PROC ResultSetInsertTests.ResultSetInsertHelperP +AS +BEGIN + CREATE TABLE #t (val INT); + INSERT INTO #t + EXEC ResultSetInsertTests.ResultSetInsertHelperQ + SELECT * FROM #t +END; +GO + +CREATE PROC ResultSetInsertTests.ResultSetInsertHelperQ +AS +BEGIN + SELECT 42 +END; +GO + +CREATE PROC ResultSetInsertTests.[test ResultSetInserts handles nested insert execs] +AS +BEGIN + CREATE TABLE #Actual (val INT); + EXEC tSQLt.ResultSetInsert 1, 'EXEC ResultSetInsertTests.ResultSetInsertHelperP', '#Actual'; + + CREATE TABLE #Expected (val INT); + INSERT INTO #Expected + VALUES (42) + + EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected'; +END; +GO diff --git a/Tests/Tests.ssmssqlproj b/Tests/Tests.ssmssqlproj index a8a5e1d36..cfd227d4c 100644 --- a/Tests/Tests.ssmssqlproj +++ b/Tests/Tests.ssmssqlproj @@ -366,6 +366,12 @@ ResultSetFilterTests.class.sql + + + + + ResultSetInsertTests.class.sql + diff --git a/tSQLtCLR/tSQLtCLR/ResultSetFilter.cs b/tSQLtCLR/tSQLtCLR/ResultSetFilter.cs index 4e7184b45..656e80f6b 100644 --- a/tSQLtCLR/tSQLtCLR/ResultSetFilter.cs +++ b/tSQLtCLR/tSQLtCLR/ResultSetFilter.cs @@ -18,6 +18,36 @@ public ResultSetFilter(TestDatabaseFacade testDatabaseFacade) this.testDatabaseFacade = testDatabaseFacade; } + public void insertSelectedResultSetToTable(SqlInt32 resultsetNo, SqlString command, SqlString table) + { + validateResultSetNumber(resultsetNo); + + SqlDataReader dataReader = testDatabaseFacade.executeCommand(command); + + List data = null; + int ResultsetCount = 0; + if (dataReader.FieldCount > 0) + { + do + { + ResultsetCount++; + if (ResultsetCount == resultsetNo) + { + data = getDataFromReader(dataReader); + break; + } + } while (dataReader.NextResult()); + } + dataReader.Close(); + if (data != null) + { + testDatabaseFacade.insertData(table, data); + } + else if (ResultsetCount != resultsetNo) + { + throw new InvalidResultSetException("Execution returned only " + ResultsetCount.ToString() + " ResultSets. ResultSet [" + resultsetNo.ToString() + "] does not exist."); + } + } public void sendSelectedResultSetToSqlContext(SqlInt32 resultsetNo, SqlString command) { validateResultSetNumber(resultsetNo); @@ -53,6 +83,16 @@ private void validateResultSetNumber(SqlInt32 resultsetNo) } } + private List getDataFromReader(SqlDataReader dataReader) + { + List rows = new List(); + while (dataReader.Read()) { + object[] recordData = new object[dataReader.FieldCount]; + dataReader.GetSqlValues(recordData); + rows.Add(recordData); + } + return rows; + } private static void sendResultsetRecords(SqlDataReader dataReader) { SqlMetaData[] meta = createMetaDataForResultset(dataReader); diff --git a/tSQLtCLR/tSQLtCLR/StoredProcedures.cs b/tSQLtCLR/tSQLtCLR/StoredProcedures.cs index 47e8152eb..c154333a7 100644 --- a/tSQLtCLR/tSQLtCLR/StoredProcedures.cs +++ b/tSQLtCLR/tSQLtCLR/StoredProcedures.cs @@ -21,6 +21,11 @@ public static void ResultSetFilter(SqlInt32 resultSetNo, SqlString command) ResultSetFilter filter = new ResultSetFilter(new TestDatabaseFacade()); filter.sendSelectedResultSetToSqlContext(resultSetNo, command); } + public static void ResultSetInsert(SqlInt32 resultSetNo, SqlString command, SqlString outputTable) + { + ResultSetFilter filter = new ResultSetFilter(new TestDatabaseFacade()); + filter.insertSelectedResultSetToTable(resultSetNo, command, outputTable); + } public static void NewConnection(SqlString command) { diff --git a/tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs b/tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs index c911abf6d..910cabe2d 100644 --- a/tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs +++ b/tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs @@ -74,7 +74,30 @@ public SqlDataReader executeCommand(SqlString Command) return dataReader; } + public void insertData(SqlString table, List data) + { + foreach (object[] row in data) { + using (SqlCommand command = new SqlCommand()) + { + command.Connection = connection; + string commandText = "INSERT INTO " + table.ToString() + " VALUES("; + int index = 1; + foreach (object val in row) { + if (index > 1) { + commandText += ","; + } + string paramName = "@p" + index.ToString(); + commandText += paramName; + command.Parameters.AddWithValue(paramName, row[index - 1]); + index += 1; + } + commandText += ")"; + command.CommandText = commandText; + command.ExecuteNonQuery(); + } + } + } protected void OnInfoMessage(object sender, SqlInfoMessageEventArgs args) { if (infoMessage.IsNull)