Skip to content

Commit 002b07b

Browse files
committed
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 (tSQLt-org#18). This is an alternative and original implementation of PR tSQLt-org#19. Signed-off-by: Paul Guyot <[email protected]>
1 parent a16745d commit 002b07b

File tree

6 files changed

+197
-0
lines changed

6 files changed

+197
-0
lines changed

Source/tSQLtCLR_CreateProcs.sql

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -14,6 +14,7 @@
1414
limitations under the License.
1515
*/
1616
IF OBJECT_ID('tSQLt.ResultSetFilter') IS NOT NULL DROP PROCEDURE tSQLt.ResultSetFilter;
17+
IF OBJECT_ID('tSQLt.ResultSetInsert') IS NOT NULL DROP PROCEDURE tSQLt.ResultSetInsert;
1718
IF OBJECT_ID('tSQLt.AssertResultSetsHaveSameMetaData') IS NOT NULL DROP PROCEDURE tSQLt.AssertResultSetsHaveSameMetaData;
1819
IF OBJECT_ID('tSQLt.NewConnection') IS NOT NULL DROP PROCEDURE tSQLt.NewConnection;
1920
IF OBJECT_ID('tSQLt.CaptureOutput') IS NOT NULL DROP PROCEDURE tSQLt.CaptureOutput;
@@ -32,6 +33,11 @@ AS
3233
EXTERNAL NAME tSQLtCLR.[tSQLtCLR.StoredProcedures].ResultSetFilter;
3334
GO
3435

36+
CREATE PROCEDURE tSQLt.ResultSetInsert @ResultsetNo INT, @Command NVARCHAR(MAX), @Table NVARCHAR(MAX)
37+
AS
38+
EXTERNAL NAME tSQLtCLR.[tSQLtCLR.StoredProcedures].ResultSetInsert;
39+
GO
40+
3541
CREATE PROCEDURE tSQLt.AssertResultSetsHaveSameMetaData @expectedCommand NVARCHAR(MAX), @actualCommand NVARCHAR(MAX)
3642
AS
3743
EXTERNAL NAME tSQLtCLR.[tSQLtCLR.StoredProcedures].AssertResultSetsHaveSameMetaData;

Tests/ResultSetInsertTests.class.sql

Lines changed: 117 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,117 @@
1+
EXEC tSQLt.NewTestClass 'ResultSetInsertTests';
2+
GO
3+
CREATE PROC ResultSetInsertTests.[test ResultSetInsert returns specified result set]
4+
AS
5+
BEGIN
6+
CREATE TABLE #Actual (val INT);
7+
8+
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';
9+
10+
CREATE TABLE #Expected (val INT);
11+
INSERT INTO #Expected
12+
SELECT 3 AS val UNION ALL SELECT 4 UNION ALL SELECT 5;
13+
14+
EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected';
15+
END;
16+
GO
17+
18+
CREATE PROC ResultSetInsertTests.[test ResultSetInsert returns specified result set with multiple columns]
19+
AS
20+
BEGIN
21+
CREATE TABLE #Actual (val1 INT, val2 VARCHAR(3));
22+
23+
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';
24+
25+
CREATE TABLE #Expected (val1 INT, val2 VARCHAR(3));
26+
INSERT INTO #Expected
27+
SELECT 3 AS val1, 'ABC' AS val2 UNION ALL SELECT 4, 'DEF' UNION ALL SELECT 5, 'GHI';
28+
29+
EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected';
30+
END;
31+
GO
32+
33+
CREATE PROC ResultSetInsertTests.[test ResultSetInsert throws error if specified result set is 1 greater than number of result sets returned]
34+
AS
35+
BEGIN
36+
DECLARE @err NVARCHAR(MAX); SET @err = '--NO Error Thrown!--';
37+
38+
CREATE TABLE #Actual (val INT);
39+
40+
BEGIN TRY
41+
EXEC tSQLt.ResultSetInsert 4, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val;', '#Actual';
42+
END TRY
43+
BEGIN CATCH
44+
SET @err = ERROR_MESSAGE();
45+
END CATCH
46+
47+
IF @err NOT LIKE '%Execution returned only 3 ResultSets. ResultSet [[]4] does not exist.%'
48+
BEGIN
49+
EXEC tSQLt.Fail 'Unexpected error message was: ', @err;
50+
END;
51+
END;
52+
GO
53+
54+
CREATE PROC ResultSetInsertTests.[test ResultSetFilter throws error if specified result set is more than 1 greater than number of result sets returned]
55+
AS
56+
BEGIN
57+
DECLARE @err NVARCHAR(MAX); SET @err = '--NO Error Thrown!--';
58+
59+
CREATE TABLE #Actual (val INT);
60+
61+
BEGIN TRY
62+
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';
63+
END TRY
64+
BEGIN CATCH
65+
SET @err = ERROR_MESSAGE();
66+
END CATCH
67+
68+
IF @err NOT LIKE '%Execution returned only 5 ResultSets. ResultSet [[]9] does not exist.%'
69+
BEGIN
70+
EXEC tSQLt.Fail 'Unexpected error message was: ', @err;
71+
END;
72+
END;
73+
GO
74+
75+
CREATE PROC ResultSetInsertTests.[test ResultSetFilter retrieves no records and throws no error if 0 is specified]
76+
AS
77+
BEGIN
78+
CREATE TABLE #Actual (val INT);
79+
80+
EXEC tSQLt.ResultSetInsert 0, 'SELECT 1 AS val; SELECT 2 AS val; SELECT 3 AS val;', '#Actual';
81+
82+
CREATE TABLE #Expected (val INT);
83+
84+
EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected';
85+
END;
86+
GO
87+
88+
CREATE PROC ResultSetInsertTests.ResultSetInsertHelperP
89+
AS
90+
BEGIN
91+
CREATE TABLE #t (val INT);
92+
INSERT INTO #t
93+
EXEC ResultSetInsertTests.ResultSetInsertHelperQ
94+
SELECT * FROM #t
95+
END;
96+
GO
97+
98+
CREATE PROC ResultSetInsertTests.ResultSetInsertHelperQ
99+
AS
100+
BEGIN
101+
SELECT 42
102+
END;
103+
GO
104+
105+
CREATE PROC ResultSetInsertTests.[test ResultSetInserts handles nested insert execs]
106+
AS
107+
BEGIN
108+
CREATE TABLE #Actual (val INT);
109+
EXEC tSQLt.ResultSetInsert 1, 'EXEC ResultSetInsertTests.ResultSetInsertHelperP', '#Actual';
110+
111+
CREATE TABLE #Expected (val INT);
112+
INSERT INTO #Expected
113+
VALUES (42)
114+
115+
EXEC tSQLt.AssertEqualsTable '#Actual', '#Expected';
116+
END;
117+
GO

Tests/Tests.ssmssqlproj

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -366,6 +366,12 @@
366366
<AssociatedConnUserName />
367367
<FullPath>ResultSetFilterTests.class.sql</FullPath>
368368
</FileNode>
369+
<FileNode Name="ResultSetInsertTests.class.sql">
370+
<AssociatedConnectionMoniker />
371+
<AssociatedConnSrvName />
372+
<AssociatedConnUserName />
373+
<FullPath>ResultSetInsertTests.class.sql</FullPath>
374+
</FileNode>
369375
<FileNode Name="Run_Methods_Tests.class.sql">
370376
<AssociatedConnectionMoniker />
371377
<AssociatedConnSrvName />

tSQLtCLR/tSQLtCLR/ResultSetFilter.cs

Lines changed: 40 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -18,6 +18,36 @@ public ResultSetFilter(TestDatabaseFacade testDatabaseFacade)
1818
this.testDatabaseFacade = testDatabaseFacade;
1919
}
2020

21+
public void insertSelectedResultSetToTable(SqlInt32 resultsetNo, SqlString command, SqlString table)
22+
{
23+
validateResultSetNumber(resultsetNo);
24+
25+
SqlDataReader dataReader = testDatabaseFacade.executeCommand(command);
26+
27+
List<object[]> data = null;
28+
int ResultsetCount = 0;
29+
if (dataReader.FieldCount > 0)
30+
{
31+
do
32+
{
33+
ResultsetCount++;
34+
if (ResultsetCount == resultsetNo)
35+
{
36+
data = getDataFromReader(dataReader);
37+
break;
38+
}
39+
} while (dataReader.NextResult());
40+
}
41+
dataReader.Close();
42+
if (data != null)
43+
{
44+
testDatabaseFacade.insertData(table, data);
45+
}
46+
else if (ResultsetCount != resultsetNo)
47+
{
48+
throw new InvalidResultSetException("Execution returned only " + ResultsetCount.ToString() + " ResultSets. ResultSet [" + resultsetNo.ToString() + "] does not exist.");
49+
}
50+
}
2151
public void sendSelectedResultSetToSqlContext(SqlInt32 resultsetNo, SqlString command)
2252
{
2353
validateResultSetNumber(resultsetNo);
@@ -53,6 +83,16 @@ private void validateResultSetNumber(SqlInt32 resultsetNo)
5383
}
5484
}
5585

86+
private List<object[]> getDataFromReader(SqlDataReader dataReader)
87+
{
88+
List<object[]> rows = new List<Object[]>();
89+
while (dataReader.Read()) {
90+
object[] recordData = new object[dataReader.FieldCount];
91+
dataReader.GetSqlValues(recordData);
92+
rows.Add(recordData);
93+
}
94+
return rows;
95+
}
5696
private static void sendResultsetRecords(SqlDataReader dataReader)
5797
{
5898
SqlMetaData[] meta = createMetaDataForResultset(dataReader);

tSQLtCLR/tSQLtCLR/StoredProcedures.cs

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -21,6 +21,11 @@ public static void ResultSetFilter(SqlInt32 resultSetNo, SqlString command)
2121
ResultSetFilter filter = new ResultSetFilter(new TestDatabaseFacade());
2222
filter.sendSelectedResultSetToSqlContext(resultSetNo, command);
2323
}
24+
public static void ResultSetInsert(SqlInt32 resultSetNo, SqlString command, SqlString outputTable)
25+
{
26+
ResultSetFilter filter = new ResultSetFilter(new TestDatabaseFacade());
27+
filter.insertSelectedResultSetToTable(resultSetNo, command, outputTable);
28+
}
2429

2530
public static void NewConnection(SqlString command)
2631
{

tSQLtCLR/tSQLtCLR/TestDatabaseFacade.cs

Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -74,7 +74,30 @@ public SqlDataReader executeCommand(SqlString Command)
7474

7575
return dataReader;
7676
}
77+
public void insertData(SqlString table, List<object[]> data)
78+
{
79+
foreach (object[] row in data) {
80+
using (SqlCommand command = new SqlCommand())
81+
{
82+
command.Connection = connection;
83+
string commandText = "INSERT INTO " + table.ToString() + " VALUES(";
84+
int index = 1;
85+
foreach (object val in row) {
86+
if (index > 1) {
87+
commandText += ",";
88+
}
89+
string paramName = "@p" + index.ToString();
90+
commandText += paramName;
91+
command.Parameters.AddWithValue(paramName, row[index - 1]);
92+
index += 1;
93+
}
94+
commandText += ")";
95+
command.CommandText = commandText;
7796

97+
command.ExecuteNonQuery();
98+
}
99+
}
100+
}
78101
protected void OnInfoMessage(object sender, SqlInfoMessageEventArgs args)
79102
{
80103
if (infoMessage.IsNull)

0 commit comments

Comments
 (0)