From cec00ef06962f6ef4614fbd44fdc3f1cccd3708f Mon Sep 17 00:00:00 2001 From: Jonathan Hall Date: Wed, 22 Feb 2017 11:08:24 +1000 Subject: [PATCH] The change addresses the issue with testing stored procedures that contain an 'INSERT INTO EXEC' https://github.com/tSQLt-org/tSQLt/issues/18 --- Experiments/Experiments.ssmssqlproj | 6 + ...erateTestsForResultsetToTableDataTypes.sql | 85 ++++ Source/tSQLtCLR_CreateProcs.sql | 5 + Tests/Tests.ssmssqlproj | 8 +- Tests/tSQLt_test_ResultSetToTable.class.sql | 444 ++++++++++++++++++ tSQLtCLR/tSQLtCLR/ResultSetToTable.cs | 150 ++++++ tSQLtCLR/tSQLtCLR/StoredProcedures.cs | 6 + tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs | 9 +- tSQLtCLR/tSQLtCLR/tSQLtCLR.csproj | 1 + 9 files changed, 712 insertions(+), 2 deletions(-) create mode 100644 Experiments/GenerateTestsForResultsetToTableDataTypes.sql create mode 100644 Tests/tSQLt_test_ResultSetToTable.class.sql create mode 100644 tSQLtCLR/tSQLtCLR/ResultSetToTable.cs diff --git a/Experiments/Experiments.ssmssqlproj b/Experiments/Experiments.ssmssqlproj index 0603c8934..b5eacddcd 100644 --- a/Experiments/Experiments.ssmssqlproj +++ b/Experiments/Experiments.ssmssqlproj @@ -43,6 +43,12 @@ GenerateTestsForResultsetFilterDataTypes.sql + + + + + GenerateTestsForResultsetToTableDataTypes.sql + 8c91a03d-f9b4-46c0-a305-b5dcc79ff907:Dev_tSQLt:True Dev_tSQLt diff --git a/Experiments/GenerateTestsForResultsetToTableDataTypes.sql b/Experiments/GenerateTestsForResultsetToTableDataTypes.sql new file mode 100644 index 000000000..3b45acb4c --- /dev/null +++ b/Experiments/GenerateTestsForResultsetToTableDataTypes.sql @@ -0,0 +1,85 @@ +/* + Copyright 2011 tSQLt + + Licensed under the Apache License, Version 2.0 (the "License"); + you may not use this file except in compliance with the License. + You may obtain a copy of the License at + + http://www.apache.org/licenses/LICENSE-2.0 + + Unless required by applicable law or agreed to in writing, software + distributed under the License is distributed on an "AS IS" BASIS, + WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + See the License for the specific language governing permissions and + limitations under the License. +*/ +SET NOCOUNT ON; + +CREATE TABLE #datatypes (example VARCHAR(MAX), datatype VARCHAR(MAX)); +GO + +INSERT INTO #datatypes (example, datatype) VALUES ('76456376', 'BIGINT') +INSERT INTO #datatypes (example, datatype) VALUES ('0x432643', 'BINARY(15)') +INSERT INTO #datatypes (example, datatype) VALUES ('1', 'BIT') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'CHAR(15)') +INSERT INTO #datatypes (example, datatype) VALUES ('12/27/2010 11:54:12.003', 'DATETIME') +INSERT INTO #datatypes (example, datatype) VALUES ('234.567', 'DECIMAL(7,4)') +INSERT INTO #datatypes (example, datatype) VALUES ('12345.6789', 'FLOAT') +INSERT INTO #datatypes (example, datatype) VALUES ('XYZ', 'IMAGE') +INSERT INTO #datatypes (example, datatype) VALUES ('13', 'INT') +INSERT INTO #datatypes (example, datatype) VALUES ('12.95', 'MONEY') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'NCHAR(15)') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'NTEXT') +INSERT INTO #datatypes (example, datatype) VALUES ('345.67', 'NUMERIC(7,4)') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'NVARCHAR(15)') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'NVARCHAR(MAX)') +INSERT INTO #datatypes (example, datatype) VALUES ('12345.6789', 'REAL') +INSERT INTO #datatypes (example, datatype) VALUES ('12/27/2010 09:35', 'SMALLDATETIME') +INSERT INTO #datatypes (example, datatype) VALUES ('13', 'SMALLINT') +INSERT INTO #datatypes (example, datatype) VALUES ('13.95', 'SMALLMONEY') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'SQL_VARIANT') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'SYSNAME') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'TEXT') +INSERT INTO #datatypes (example, datatype) VALUES ('0x1234', 'TIMESTAMP') +INSERT INTO #datatypes (example, datatype) VALUES ('7', 'TINYINT') +INSERT INTO #datatypes (example, datatype) VALUES ('F12AF25F-E043-4475-ADD1-96B8BBC6F16E', 'UNIQUEIDENTIFIER') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'VARBINARY(15)') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'VARBINARY(MAX)') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'VARCHAR(15)') +INSERT INTO #datatypes (example, datatype) VALUES ('ABCDEF', 'VARCHAR(MAX)') +INSERT INTO #datatypes (example, datatype) VALUES ('hi', 'XML') + + +DECLARE @example VARCHAR(MAX), @datatype VARCHAR(MAX); +DECLARE recs CURSOR LOCAL FAST_FORWARD FOR +SELECT example, datatype +FROM #datatypes +ORDER BY datatype; + +OPEN recs +FETCH NEXT FROM recs INTO @example, @datatype; + +PRINT '-- GENERATED WITH tSQLt\Experiments\GenerateTestsForResultsetToTableDataTypes.sql'; +PRINT 'CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable can handle each datatype]'; +PRINT 'AS'; +PRINT 'BEGIN'; + + WHILE @@FETCH_STATUS = 0 + BEGIN + + PRINT ' EXEC tSQLt.AssertResultSetsHaveSameMetaData'; + PRINT ' ''SELECT CAST(''''' + @example + ''''' AS ' + @datatype + ') AS val;'',' + PRINT ' ''CREATE TABLE #Actual (val ' + @datatype + ' NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''''SELECT CAST(''''''''' + @example + ''''''''' AS ' + @datatype + ') AS val;''''; SELECT * FROM #Actual;'';'; + + FETCH NEXT FROM recs INTO @example, @datatype; + END; + +PRINT 'END;'; +PRINT 'GO'; +PRINT ''; + +CLOSE recs +DEALLOCATE recs +GO + +DROP TABLE #datatypes; \ No newline at end of file diff --git a/Source/tSQLtCLR_CreateProcs.sql b/Source/tSQLtCLR_CreateProcs.sql index b15259899..9e843054f 100644 --- a/Source/tSQLtCLR_CreateProcs.sql +++ b/Source/tSQLtCLR_CreateProcs.sql @@ -22,6 +22,11 @@ AS EXTERNAL NAME tSQLtCLR.[tSQLtCLR.StoredProcedures].ResultSetFilter; GO +CREATE PROCEDURE tSQLt.ResultSetToTable @targetTable NVARCHAR(MAX), @ResultsetNo INT, @Command NVARCHAR(MAX) +AS +EXTERNAL NAME tSQLtCLR.[tSQLtCLR.StoredProcedures].ResultSetToTable +GO + CREATE PROCEDURE tSQLt.AssertResultSetsHaveSameMetaData @expectedCommand NVARCHAR(MAX), @actualCommand NVARCHAR(MAX) AS EXTERNAL NAME tSQLtCLR.[tSQLtCLR.StoredProcedures].AssertResultSetsHaveSameMetaData; diff --git a/Tests/Tests.ssmssqlproj b/Tests/Tests.ssmssqlproj index fbd9eac4f..bd5962800 100644 --- a/Tests/Tests.ssmssqlproj +++ b/Tests/Tests.ssmssqlproj @@ -15,7 +15,7 @@ NotSpecified Microsoft SQL Server Management Studio - Query - + @@ -211,6 +211,12 @@ Run_Methods_Tests.class.sql + + + + + tSQLt_test_ResultSetToTable.class.sql + 8c91a03d-f9b4-46c0-a305-b5dcc79ff907:Dev_tSQLt:True Dev_tSQLt diff --git a/Tests/tSQLt_test_ResultSetToTable.class.sql b/Tests/tSQLt_test_ResultSetToTable.class.sql new file mode 100644 index 000000000..e66ce9c7d --- /dev/null +++ b/Tests/tSQLt_test_ResultSetToTable.class.sql @@ -0,0 +1,444 @@ +------------------------------------------------------- +-- These tests ensure compatablity with ResultSetFilter +-- +-- Basically the same tests with: +-- 'INSERT INTO #Actual EXEC tSQLt.ResultSetFilter' +-- Replaced with: +-- 'EXEC tSQLt.ResultSetToTable #Actual ' +------------------------------------------------------- +EXEC tSQLt.NewTestClass 'tSQLt_test_ResultSetToTable'; +GO +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) returns specified result set] +AS +BEGIN + CREATE TABLE #Actual (val INT); + + EXEC tSQLt.ResultSetToTable #Actual, 3, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val UNION ALL SELECT 4 UNION ALL SELECT 5;'; + + 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 tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) returns specified result set with multiple columns] +AS +BEGIN + CREATE TABLE #Actual (val1 INT, val2 VARCHAR(3)); + + EXEC tSQLt.ResultSetToTable #Actual, 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;'; + + 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 tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) 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!--'; + + BEGIN TRY + CREATE TABLE #Actual (val INT); + EXEC tSQLt.ResultSetToTable #Actual, 4, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val;'; + 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 tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) throws error if result set requested is greater than number of result sets returned] +AS +BEGIN + DECLARE @err NVARCHAR(MAX); SET @err = '--NO Error Thrown!--'; + + BEGIN TRY + CREATE TABLE #Actual (val INT); + EXEC tSQLt.ResultSetToTable #Actual, 9, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val; SELECT 4 AS val; SELECT 5 AS val;'; + 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 tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) retrieves no records and throws no error if 0 is specified] +AS +BEGIN + CREATE TABLE #Actual (val INT); + + EXEC tSQLt.ResultSetToTable #Actual, 0, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val;'; + + CREATE TABLE #Expected (val INT); + + EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) retrieves no result set if 0 is specified] +AS +BEGIN + DECLARE @err NVARCHAR(MAX); SET @err = '--NO Error Thrown!--'; + + BEGIN TRY + CREATE TABLE #Actual (val INT); + EXEC tSQLt.ResultSetToTable #Actual, 1, 'EXEC tSQLt.ResultSetFilter 0, ''SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val;'';'; + END TRY + BEGIN CATCH + SET @err = ERROR_MESSAGE(); + END CATCH + + IF @err NOT LIKE '%Execution returned only 0 ResultSets. ResultSet [[]1] does not exist.%' + BEGIN + EXEC tSQLt.Fail 'Unexpected error message was: ', @err; + END; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) handles code not returning a result set] +AS +BEGIN + DECLARE @err NVARCHAR(MAX); SET @err = '--NO Error Thrown!--'; + + BEGIN TRY + CREATE TABLE #Actual (val INT); + EXEC tSQLt.ResultSetToTable #Actual, 1, 'DECLARE @NoOp INT;'; + END TRY + BEGIN CATCH + SET @err = ERROR_MESSAGE(); + END CATCH + + IF @err NOT LIKE '%Execution returned only 0 ResultSets. ResultSet [[]1] does not exist.%' + BEGIN + EXEC tSQLt.Fail 'Unexpected error message was: ', @err; + END; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) throws no error if code is not returning a result set and 0 is passed in] +AS +BEGIN + CREATE TABLE #Actual (val INT); + EXEC tSQLt.ResultSetToTable #Actual, 0,'DECLARE @NoOp INT;'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) throws error if result set number NULL specified] +AS +BEGIN + DECLARE @err NVARCHAR(MAX); SET @err = '--NO Error Thrown!--'; + + BEGIN TRY + CREATE TABLE #Actual (val INT); + EXEC tSQLt.ResultSetToTable #Actual, NULL, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val;'; + END TRY + BEGIN CATCH + SET @err = ERROR_MESSAGE(); + END CATCH + + IF @err NOT LIKE '%ResultSet index begins at 1. ResultSet index [[]Null] is invalid.%' + BEGIN + EXEC tSQLt.Fail 'Unexpected error message was: ', @err; + END; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) throws error if result set number of less than 0 specified] +AS +BEGIN + DECLARE @err NVARCHAR(MAX); SET @err = ''; + + BEGIN TRY + CREATE TABLE #Actual (val INT); + EXEC tSQLt.ResultSetToTable #Actual, -1, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val;'; + END TRY + BEGIN CATCH + SET @err = ERROR_MESSAGE(); + END CATCH + + IF @err NOT LIKE '%ResultSet index begins at 1. ResultSet index %-1% is invalid.%' + BEGIN + EXEC tSQLt.Fail 'Unexpected error message was: ', @err; + END; +END; +GO + +-- GENERATED WITH tSQLt\Experiments\GenerateTestsForResultsetToTableDataTypes.sql +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) can handle each datatype] +AS +BEGIN + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''76456376'' AS BIGINT) AS val;', + 'CREATE TABLE #Actual (val BIGINT NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''76456376'''' AS BIGINT) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''0x432643'' AS BINARY(15)) AS val;', + 'CREATE TABLE #Actual (val BINARY(15) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''0x432643'''' AS BINARY(15)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''1'' AS BIT) AS val;', + 'CREATE TABLE #Actual (val BIT NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''1'''' AS BIT) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS CHAR(15)) AS val;', + 'CREATE TABLE #Actual (val CHAR(15) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS CHAR(15)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''12/27/2010 11:54:12.003'' AS DATETIME) AS val;', + 'CREATE TABLE #Actual (val DATETIME NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''12/27/2010 11:54:12.003'''' AS DATETIME) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''234.567'' AS DECIMAL(7,4)) AS val;', + 'CREATE TABLE #Actual (val DECIMAL(7,4) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''234.567'''' AS DECIMAL(7,4)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''12345.6789'' AS FLOAT) AS val;', + 'CREATE TABLE #Actual (val FLOAT NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''12345.6789'''' AS FLOAT) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''XYZ'' AS IMAGE) AS val;', + 'CREATE TABLE #Actual (val IMAGE NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''XYZ'''' AS IMAGE) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''13'' AS INT) AS val;', + 'CREATE TABLE #Actual (val INT NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''13'''' AS INT) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''12.95'' AS MONEY) AS val;', + 'CREATE TABLE #Actual (val MONEY NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''12.95'''' AS MONEY) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS NCHAR(15)) AS val;', + 'CREATE TABLE #Actual (val NCHAR(15) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS NCHAR(15)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS NTEXT) AS val;', + 'CREATE TABLE #Actual (val NTEXT NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS NTEXT) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''345.67'' AS NUMERIC(7,4)) AS val;', + 'CREATE TABLE #Actual (val NUMERIC(7,4) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''345.67'''' AS NUMERIC(7,4)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS NVARCHAR(15)) AS val;', + 'CREATE TABLE #Actual (val NVARCHAR(15) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS NVARCHAR(15)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS NVARCHAR(MAX)) AS val;', + 'CREATE TABLE #Actual (val NVARCHAR(MAX) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS NVARCHAR(MAX)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''12345.6789'' AS REAL) AS val;', + 'CREATE TABLE #Actual (val REAL NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''12345.6789'''' AS REAL) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''12/27/2010 09:35'' AS SMALLDATETIME) AS val;', + 'CREATE TABLE #Actual (val SMALLDATETIME NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''12/27/2010 09:35'''' AS SMALLDATETIME) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''13'' AS SMALLINT) AS val;', + 'CREATE TABLE #Actual (val SMALLINT NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''13'''' AS SMALLINT) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''13.95'' AS SMALLMONEY) AS val;', + 'CREATE TABLE #Actual (val SMALLMONEY NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''13.95'''' AS SMALLMONEY) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS SQL_VARIANT) AS val;', + 'CREATE TABLE #Actual (val SQL_VARIANT NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS SQL_VARIANT) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS SYSNAME) AS val;', + 'CREATE TABLE #Actual (val SYSNAME NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS SYSNAME) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS TEXT) AS val;', + 'CREATE TABLE #Actual (val TEXT NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS TEXT) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''0x1234'' AS TIMESTAMP) AS val;', + 'CREATE TABLE #Actual (val TIMESTAMP NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''0x1234'''' AS TIMESTAMP) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''7'' AS TINYINT) AS val;', + 'CREATE TABLE #Actual (val TINYINT NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''7'''' AS TINYINT) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''F12AF25F-E043-4475-ADD1-96B8BBC6F16E'' AS UNIQUEIDENTIFIER) AS val;', + 'CREATE TABLE #Actual (val UNIQUEIDENTIFIER NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''F12AF25F-E043-4475-ADD1-96B8BBC6F16E'''' AS UNIQUEIDENTIFIER) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS VARBINARY(15)) AS val;', + 'CREATE TABLE #Actual (val VARBINARY(15) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS VARBINARY(15)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS VARBINARY(MAX)) AS val;', + 'CREATE TABLE #Actual (val VARBINARY(MAX) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS VARBINARY(MAX)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS VARCHAR(15)) AS val;', + 'CREATE TABLE #Actual (val VARCHAR(15) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS VARCHAR(15)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''ABCDEF'' AS VARCHAR(MAX)) AS val;', + 'CREATE TABLE #Actual (val VARCHAR(MAX) NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''ABCDEF'''' AS VARCHAR(MAX)) AS val;''; SELECT * FROM #Actual;'; + EXEC tSQLt.AssertResultSetsHaveSameMetaData + 'SELECT CAST(''hi'' AS XML) AS val;', + 'CREATE TABLE #Actual (val XML NULL); EXEC tSQLt.ResultSetToTable #Actual, 1, ''SELECT CAST(''''hi'''' AS XML) AS val;''; SELECT * FROM #Actual;'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) produces only requested columns when underlying table contains primary key] +AS +BEGIN + CREATE TABLE BaseTable (i INT PRIMARY KEY, v VARCHAR(15)); + INSERT INTO BaseTable (i, v) VALUES (1, 'hello'); + + CREATE TABLE #Actual (v VARCHAR(15)); + EXEC tSQLt.ResultSetToTable #Actual, 1, 'SELECT v FROM BaseTable'; + + CREATE TABLE #Expected (v VARCHAR(15)); + INSERT INTO #Expected (v) VALUES ('hello'); + + EXEC tSQLt.AssertEqualsTable '#Expected', '#Actual'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) produces only requested columns when a join on foreign keys is performed] +AS +BEGIN + CREATE TABLE BaseTable1 (i1 INT PRIMARY KEY, v1 VARCHAR(15)); + INSERT INTO BaseTable1 (i1, v1) VALUES (1, 'hello'); + + CREATE TABLE BaseTable2 (i2 INT PRIMARY KEY, i1 INT FOREIGN KEY REFERENCES BaseTable1(i1), v2 VARCHAR(15)); + INSERT INTO BaseTable2 (i2, i1, v2) VALUES (1, 1, 'goodbye'); + + CREATE TABLE #Actual (v1 VARCHAR(15), v2 VARCHAR(15)); + EXEC tSQLt.ResultSetToTable #Actual, 1, 'SELECT v1, v2 FROM BaseTable1 JOIN BaseTable2 ON BaseTable1.i1 = BaseTable2.i1'; + + CREATE TABLE #Expected (v1 VARCHAR(15), v2 VARCHAR(15)); + INSERT INTO #Expected (v1, v2) VALUES ('hello', 'goodbye'); + + EXEC tSQLt.AssertEqualsTable '#Expected', '#Actual'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) produces only requested columns when a unique column exists] +AS +BEGIN + CREATE TABLE BaseTable1 (i1 INT UNIQUE, v1 VARCHAR(15)); + INSERT INTO BaseTable1 (i1, v1) VALUES (1, 'hello'); + + CREATE TABLE #Actual (v1 VARCHAR(15)); + EXEC tSQLt.ResultSetToTable #Actual, 1, 'SELECT v1 FROM BaseTable1'; + + CREATE TABLE #Expected (v1 VARCHAR(15)); + INSERT INTO #Expected (v1) VALUES ('hello'); + + EXEC tSQLt.AssertEqualsTable '#Expected', '#Actual'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable (Compatability) produces only requested columns when a check constraint exists] +AS +BEGIN + CREATE TABLE BaseTable1 (i1 INT CHECK(i1 = 1), v1 VARCHAR(15)); + INSERT INTO BaseTable1 (i1, v1) VALUES (1, 'hello'); + + CREATE TABLE #Actual (v1 VARCHAR(15)); + EXEC tSQLt.ResultSetToTable #Actual, 1, 'SELECT v1 FROM BaseTable1'; + + CREATE TABLE #Expected (v1 VARCHAR(15)); + INSERT INTO #Expected (v1) VALUES ('hello'); + + EXEC tSQLt.AssertEqualsTable '#Expected', '#Actual'; +END; +GO + +------------------------------------------------------- +-- The remaining tests are for ResultSetToTable +-- Ensuring it can work without failing with INSERT EXEC nested issue +------------------------------------------------------- +CREATE PROC tSQLt_test_ResultSetToTable.[_DataReturnTable] +AS +BEGIN + SELECT CAST('TEST' AS VARCHAR(15)) as col1, CAST(123 AS INT) AS col2 + UNION + SELECT 'TEST', 456 +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[_DataUsesInsertExec] +AS +BEGIN + DECLARE @cachedResults TABLE(col1 VARCHAR(15) NULL , col2 int NULL); + INSERT INTO @cachedResults EXEC tSQLt_test_ResultSetToTable.[_DataReturnTable] + + -- Multiple Returns using @cachedResults + SELECT col1, SUM(col2) AS col2 FROM @cachedResults GROUP BY col1; + SELECT col1, MIN(col2) AS col2 FROM @cachedResults GROUP BY col1; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetFilter Known Issue that INSERT EXEC cannot be nested] +AS BEGIN + -- This will start fail once SQL server allows nested INSERT EXEC + -- https://github.com/tSQLt-org/tSQLt/issues/18 + DECLARE @actual2 TABLE(col1 VARCHAR(15) NULL, col2 int NULL); + + EXEC tSQLt.ExpectException @Message = 'An INSERT EXEC statement cannot be nested.'; + + INSERT INTO @actual2 EXEC tSQLt.ResultSetFilter 1, 'EXEC tSQLt_test_ResultSetToTable._DataUsesInsertExec'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable returns specified result set (1 of 2)] +AS BEGIN + CREATE TABLE #expected (col1 VARCHAR(15) NULL , col2 int NULL); + INSERT INTO #expected VALUES ('TEST', 579); -- 123 + 456 + + CREATE TABLE #actual (col1 VARCHAR(15) NULL , col2 int NULL); + EXEC tSQLt.ResultSetToTable #actual, 1, 'EXEC tSQLt_test_ResultSetToTable._DataUsesInsertExec' + + EXEC tSQLt.AssertEqualsTable '#expected', '#actual'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable returns specified result set (2 of 2)] +AS BEGIN + CREATE TABLE #expected (col1 VARCHAR(15) NULL , col2 int NULL); + INSERT INTO #expected VALUES ('TEST', 123 ); + + CREATE TABLE #actual (col1 VARCHAR(15) NULL , col2 int NULL); + EXEC tSQLt.ResultSetToTable #actual, 2, 'EXEC tSQLt_test_ResultSetToTable._DataUsesInsertExec' + + EXEC tSQLt.AssertEqualsTable '#expected', '#actual'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable uses column names to populate target table] +AS +BEGIN + CREATE TABLE #Actual (val1 VARCHAR(10), val2 INT); + EXEC tSQLt.ResultSetToTable #Actual, 1, 'SELECT 2 AS val2, ''ONE'' as val1'; + + CREATE TABLE #Expected (val1 VARCHAR(10), val2 INT); + INSERT INTO #Expected VALUES ('ONE', 2); + + EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable ignores columns not in target table] +AS +BEGIN + CREATE TABLE #Actual (val1 VARCHAR(10), val2 INT); + EXEC tSQLt.ResultSetToTable #Actual, 1, 'SELECT 2 AS val2, ''ONE'' as val1, 4 as ExtraColumn'; + + CREATE TABLE #Expected (val1 VARCHAR(10), val2 INT); + INSERT INTO #Expected VALUES ('ONE', 2); + + EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected'; +END; +GO + +CREATE PROC tSQLt_test_ResultSetToTable.[test ResultSetToTable skips columns not in result set] +AS +BEGIN + CREATE TABLE #Actual (val1 INT, notpopulated INT); + EXEC tSQLt.ResultSetToTable #Actual, 1, 'SELECT 1 AS val1'; + + CREATE TABLE #Expected (val1 INT, notpopulated INT); + INSERT INTO #Expected VALUES (1 , null); + + EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected'; +END; +GO \ No newline at end of file diff --git a/tSQLtCLR/tSQLtCLR/ResultSetToTable.cs b/tSQLtCLR/tSQLtCLR/ResultSetToTable.cs new file mode 100644 index 000000000..aa2098eec --- /dev/null +++ b/tSQLtCLR/tSQLtCLR/ResultSetToTable.cs @@ -0,0 +1,150 @@ +/* + * Copyright 2017 Jonathan Hall + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ +using System; +using System.Collections.Generic; +using System.Data; +using System.Data.SqlClient; +using System.Data.SqlTypes; +using System.Text; + +namespace tSQLtCLR +{ + class ResultSetToTable + { + private TestDatabaseFacade testDatabaseFacade; + + public ResultSetToTable(TestDatabaseFacade testDatabaseFacade) + { + this.testDatabaseFacade = testDatabaseFacade; + } + + + /// + /// Replacement for "INSERT INTO [table] EXEC" pattern this works like tSQLt.ResultSetFilter + /// with the addition of the extra TargetTable param + /// + /// This method will: + /// - Execute the desired command and + /// - Extract the selected result set + /// - Insert new rows into the TargetTable. + /// + /// Notes: + /// - Unlike ResultSetFilter this cannot stream the new rows into the target table, they're kept in memory until after command is finished. + /// - Only columns in common to the result set and target table will be populated; + /// - extra result columns will be discarded + /// - extra target table columns will be populated with NULL (will fail if these are 'NOT NULL') + /// + /// + /// Target Table (this can be a #TemporaryTable, but not a @variable) + /// If command returns multiple result sets select which one to capture + /// SQL String that will be executed + /// + /// + /// + internal void sendSelectedResultSetToTable(string targetTableName, SqlInt32 resultsetNo, SqlString command) + { + validateResultSetNumber(resultsetNo); + + // Establish a updatable DataTable linked to the target table + using (var adapter = testDatabaseFacade.getSQLAdapterForCommand("SELECT TOP 0 * FROM " + targetTableName)) + // ReSharper disable once UnusedVariable + // SqlCommandBuilder is needed to allow targetDataSet to be updated. + using (var builder = new SqlCommandBuilder(adapter)) + using (var targetDataSet = new DataSet()) + { + adapter.Fill(targetDataSet); + var targetTable = targetDataSet.Tables[0]; + + // Run the desired command using a SqlDataRreader so that the results can be streamed. + using (var dataReader = testDatabaseFacade.executeCommand(command)) + { + // Find the relevent result by steping througth Result Sets + int resultsetCount = 0; + do + { + // ignore blank Result Sets. + if (dataReader.HasRows || dataReader.FieldCount > 0) + { + resultsetCount++; + if (resultsetCount == resultsetNo) + break; + } + } while (dataReader.NextResult()); + + if (resultsetCount < resultsetNo) + { + throw new InvalidResultSetException( + string.Format("Execution returned only {0} ResultSets. ResultSet [{1}] does not exist.", + resultsetCount, resultsetNo)); + } + + + // 4. Work out which columns to keep + // and Extract columns from result's schema + var schemaTable = dataReader.GetSchemaTable(); + if (schemaTable == null) + return; // ResultSet has no data. + + + var availableColumns = new Dictionary(); + foreach (DataRow c in schemaTable.Rows) + { + availableColumns.Add((string)c["ColumnName"], (int)c["ColumnOrdinal"]); + } + + // 3b. Use target table schema to determine which columns are common. + var commonColumns = new Dictionary(); + foreach (DataColumn k in targetTable.Columns) + { + int index; + if (availableColumns.TryGetValue(k.ToString(), out index)) + { + commonColumns.Add(k, index); + } + } + + // Step 4. Itterate through Results creating new rows in Target Table + object[] recordData = new object[dataReader.FieldCount]; + while (dataReader.Read()) + { + dataReader.GetValues(recordData); + + var newrow = targetTable.NewRow(); + foreach (KeyValuePair kvp in commonColumns) + { + newrow[kvp.Key] = recordData[kvp.Value]; + } + targetTable.Rows.Add(newrow); + } + } + adapter.Update(targetDataSet); + } + } + + private void validateResultSetNumber(SqlInt32 resultsetNo) + { + if (resultsetNo < 0 || resultsetNo.IsNull) + { + throw new InvalidResultSetException("ResultSet index begins at 1. ResultSet index [" + resultsetNo.ToString() + "] is invalid."); + } + } + + } +} diff --git a/tSQLtCLR/tSQLtCLR/StoredProcedures.cs b/tSQLtCLR/tSQLtCLR/StoredProcedures.cs index 47e8152eb..1bdb84248 100644 --- a/tSQLtCLR/tSQLtCLR/StoredProcedures.cs +++ b/tSQLtCLR/tSQLtCLR/StoredProcedures.cs @@ -22,6 +22,12 @@ public static void ResultSetFilter(SqlInt32 resultSetNo, SqlString command) filter.sendSelectedResultSetToSqlContext(resultSetNo, command); } + public static void ResultSetToTable(string targetTable, SqlInt32 resultsetNo, SqlString command) + { + ResultSetToTable filter = new ResultSetToTable(new TestDatabaseFacade()); + filter.sendSelectedResultSetToTable(targetTable, resultsetNo, command); + } + public static void NewConnection(SqlString command) { CommandExecutor executor = new CommandExecutor(); diff --git a/tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs b/tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs index c911abf6d..0c780dcd6 100644 --- a/tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs +++ b/tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs @@ -69,12 +69,19 @@ public SqlDataReader executeCommand(SqlString Command) cmd.Connection = connection; cmd.CommandText = Command.ToString(); - + SqlDataReader dataReader = cmd.ExecuteReader(CommandBehavior.KeyInfo); return dataReader; } + public SqlDataAdapter getSQLAdapterForCommand(SqlString Command) + { + infoMessage = SqlString.Null; + connection.InfoMessage += OnInfoMessage; + return new SqlDataAdapter(Command.ToString(), connection); + } + protected void OnInfoMessage(object sender, SqlInfoMessageEventArgs args) { if (infoMessage.IsNull) diff --git a/tSQLtCLR/tSQLtCLR/tSQLtCLR.csproj b/tSQLtCLR/tSQLtCLR/tSQLtCLR.csproj index e6d0e81b1..2e7921e60 100644 --- a/tSQLtCLR/tSQLtCLR/tSQLtCLR.csproj +++ b/tSQLtCLR/tSQLtCLR/tSQLtCLR.csproj @@ -80,6 +80,7 @@ +