Skip to content

Commit 42c0668

Browse files
committed
FIX: @ids param works on either side of join
1 parent 04162f2 commit 42c0668

File tree

5 files changed

+94
-10
lines changed

5 files changed

+94
-10
lines changed

SqlDataComparison.proj

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2,7 +2,7 @@
22

33
<PropertyGroup>
44
<PackageId>MightyOrm.SqlDataComparison</PackageId>
5-
<Version>1.0.2</Version>
5+
<Version>1.0.3</Version>
66
<OutputPath>build\</OutputPath>
77
<OutputInstall>Install.sql</OutputInstall>
88
<OutputInstallMaster>InstallMaster.sql</OutputInstallMaster>

src/core/SqlDataComparison.sql

Lines changed: 2 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -229,7 +229,8 @@ BEGIN
229229
EXEC @retval = internals.ProcessIdsParam
230230
@ids = @ids,
231231
@idsWhere = @idsWhere OUTPUT,
232-
@key_columns = @key_columns
232+
@key_columns = @key_columns,
233+
@mapped_columns = @mapped_columns
233234

234235
IF @retval <> 0 OR @@ERROR <> 0 GOTO error
235236

src/internals/ProcessIdsParam.sql

Lines changed: 25 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -6,7 +6,8 @@ GO
66
CREATE PROCEDURE [internals].[ProcessIdsParam]
77
@ids NVARCHAR(MAX),
88
@idsWhere NVARCHAR(MAX) OUTPUT,
9-
@key_columns internals.ColumnsTable READONLY
9+
@key_columns internals.ColumnsTable READONLY,
10+
@mapped_columns internals.ColumnsTable READONLY
1011
AS
1112
BEGIN
1213
SET NOCOUNT ON;
@@ -47,13 +48,25 @@ BEGIN
4748
GOTO error
4849
END
4950

50-
SELECT @i = 0, @idsWhere = ''
51+
SELECT @i = 0, @idsWhere = '('
52+
53+
SELECT @idsWhere = @idsWhere + CASE WHEN @i = 0 THEN '' ELSE ' AND ' END + '[ours].' + QUOTENAME(kc.name) + CASE WHEN @i = 0 THEN ' >= ' ELSE ' <= ' END + CAST(i.id AS NVARCHAR(MAX)), @i = @i + 1
54+
FROM #ids i
55+
FULL OUTER JOIN @key_columns kc
56+
ON 1 = 1
57+
ORDER BY i.orderBy
5158

52-
SELECT @idsWhere = @idsWhere + CASE WHEN @i = 0 THEN '' ELSE ' AND ' END + '[ours].' + kc.name + CASE WHEN @i = 0 THEN ' >= ' ELSE ' <= ' END + CAST(i.id AS NVARCHAR(MAX)), @i = @i + 1
59+
SELECT @i = 0, @idsWhere = @idsWhere + ') OR ('
60+
61+
SELECT @idsWhere = @idsWhere + CASE WHEN @i = 0 THEN '' ELSE ' AND ' END + '[theirs].' + QUOTENAME(m.name) + CASE WHEN @i = 0 THEN ' >= ' ELSE ' <= ' END + CAST(i.id AS NVARCHAR(MAX)), @i = @i + 1
5362
FROM #ids i
5463
FULL OUTER JOIN @key_columns kc
5564
ON 1 = 1
65+
INNER JOIN @mapped_columns m
66+
ON kc.column_id = m.column_id
5667
ORDER BY i.orderBy
68+
69+
SELECT @i = 0, @idsWhere = @idsWhere + ')'
5770
END
5871
ELSE
5972
BEGIN
@@ -76,10 +89,18 @@ BEGIN
7689

7790
SELECT @i = 0, @idsWhere = ''
7891

79-
SELECT @idsWhere = @idsWhere + CASE WHEN @i = 0 THEN '' ELSE ' OR ' END + '[ours].' + kc.name + ' = ' + CAST(i.id AS NVARCHAR(MAX)), @i = @i + 1
92+
SELECT @idsWhere =
93+
@idsWhere +
94+
CASE WHEN @i = 0 THEN '' ELSE ' OR ' END +
95+
'[ours].' + QUOTENAME(kc.name) + ' = ' + CAST(i.id AS NVARCHAR(MAX)) +
96+
' OR ' +
97+
'[theirs].' + QUOTENAME(m.name) + ' = ' + CAST(i.id AS NVARCHAR(MAX)),
98+
@i = @i + 1
8099
FROM #ids i
81100
FULL OUTER JOIN @key_columns kc
82101
ON 1 = 1
102+
INNER JOIN @mapped_columns m
103+
ON kc.column_id = m.column_id
83104
ORDER BY i.orderBy
84105
END
85106
END

tests/testIds.sql

Lines changed: 34 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -4,7 +4,7 @@ GO
44
EXEC tSQLt.NewTestClass 'testIds';
55
GO
66

7-
CREATE PROCEDURE testIds.[test basic ids set param works]
7+
CREATE PROCEDURE testIds.[test ids set param works when right side is NULL]
88
AS
99
BEGIN
1010
DECLARE @CRLF CHAR(2) = CHAR(13) + CHAR(10)
@@ -16,12 +16,27 @@ BEGIN
1616

1717
EXEC tSQLt.ExpectException @Message, 16, 1
1818

19-
-- TO DO: This needs to work whichever side @ids matches on, but currently only checks ours side
2019
EXEC CompareData 'SqlUtilsTests_B..AddressTypes', 'SqlUtilsTests_A..AddressTypes', @ids = '2'
2120
END
2221
GO
2322

24-
CREATE PROCEDURE testIds.[test basic ids range param works]
23+
CREATE PROCEDURE testIds.[test ids set param works when left side is NULL]
24+
AS
25+
BEGIN
26+
DECLARE @CRLF CHAR(2) = CHAR(13) + CHAR(10)
27+
28+
DECLARE @Message NVARCHAR(MAX) =
29+
'Data differences found between OURS <<< [SqlUtilsTests_A].[dbo].[AddressTypes] and THEIRS >>> [SqlUtilsTests_B].[dbo].[AddressTypes].' + @CRLF +
30+
' - Switch to results window to view differences.' + @CRLF +
31+
' - Call [Import|Export][Added|Deleted|Changed|All] (e.g. ImportAdded) with the same arguments to transfer changes.' + @CRLF
32+
33+
EXEC tSQLt.ExpectException @Message, 16, 1
34+
35+
EXEC CompareData 'SqlUtilsTests_A..AddressTypes', 'SqlUtilsTests_B..AddressTypes', @ids = '2'
36+
END
37+
GO
38+
39+
CREATE PROCEDURE testIds.[test ids range param works when right side is null]
2540
AS
2641
BEGIN
2742
DECLARE @CRLF CHAR(2) = CHAR(13) + CHAR(10)
@@ -33,11 +48,26 @@ BEGIN
3348

3449
EXEC tSQLt.ExpectException @Message, 16, 1
3550

36-
-- TO DO: This needs to work whichever side @ids matches on, but currently only checks ours side
3751
EXEC CompareData 'SqlUtilsTests_B..AddressTypes', 'SqlUtilsTests_A..AddressTypes', @ids = '1-2'
3852
END
3953
GO
4054

55+
CREATE PROCEDURE testIds.[test ids range param works when left side is null]
56+
AS
57+
BEGIN
58+
DECLARE @CRLF CHAR(2) = CHAR(13) + CHAR(10)
59+
60+
DECLARE @Message NVARCHAR(MAX) =
61+
'Data differences found between OURS <<< [SqlUtilsTests_A].[dbo].[AddressTypes] and THEIRS >>> [SqlUtilsTests_B].[dbo].[AddressTypes].' + @CRLF +
62+
' - Switch to results window to view differences.' + @CRLF +
63+
' - Call [Import|Export][Added|Deleted|Changed|All] (e.g. ImportAdded) with the same arguments to transfer changes.' + @CRLF
64+
65+
EXEC tSQLt.ExpectException @Message, 16, 1
66+
67+
EXEC CompareData 'SqlUtilsTests_A..AddressTypes', 'SqlUtilsTests_B..AddressTypes', @ids = '1-2'
68+
END
69+
GO
70+
4171
CREATE PROCEDURE testIds.[test empty ids param reported correctly]
4272
AS
4373
BEGIN

tests/testMapping.sql

Lines changed: 32 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -17,7 +17,39 @@ BEGIN
1717
EXEC tSQLt.ExpectException @Message, 16, 1
1818

1919
EXEC CompareData 'SqlUtilsTests_A..AddressTypes', 'SqlUtilsTests_C..AddressMatch', @map = 'AddressTypeID,ID;AddressType,Type'
20+
END
21+
GO
22+
23+
CREATE PROCEDURE testMapping.[test map plus ids param works]
24+
AS
25+
BEGIN
26+
DECLARE @CRLF CHAR(2) = CHAR(13) + CHAR(10)
2027

28+
-- make mismatches on both sides
29+
SET IDENTITY_INSERT SqlUtilsTests_A.dbo.AddressTypes ON;
30+
INSERT INTO SqlUtilsTests_A.dbo.AddressTypes (AddressTypeID, AddressType)
31+
VALUES (3, 'Work')
32+
SET IDENTITY_INSERT SqlUtilsTests_A.dbo.AddressTypes OFF;
33+
DELETE FROM SqlUtilsTests_C..AddressMatch WHERE ID = 3
34+
UPDATE SqlUtilsTests_A.dbo.AddressTypes SET AddressType = 'Test' WHERE AddressTypeID = 1
35+
36+
EXEC tSQLt.CaptureOutput 'EXEC ImportAll ''SqlUtilsTests_A..AddressTypes'', ''SqlUtilsTests_C..AddressMatch'', @map = ''AddressTypeID,ID;AddressType,Type'', @ids = ''1-3'''
37+
SELECT CAST (
38+
@CRLF +
39+
'Importing added rows...' + @CRLF +
40+
'Requested import completed with no errors. Transferred 1 rows from [theirs] into [ours].' + @CRLF +
41+
'' + @CRLF +
42+
'Importing deleted rows...' + @CRLF +
43+
'Requested import completed with no errors. Deleted 1 rows from [ours].' + @CRLF +
44+
'' + @CRLF +
45+
'Importing changed rows...' + @CRLF +
46+
'Requested import completed with no errors. Updated 1 rows in [ours] with data from [theirs].' + @CRLF +
47+
'' + @CRLF +
48+
'No data differences found between OURS <<< [SqlUtilsTests_A].[dbo].[AddressTypes] and THEIRS >>> [SqlUtilsTests_C].[dbo].[AddressMatch].' + @CRLF
49+
AS NVARCHAR(MAX)) AS OutputText
50+
INTO #TestOutput
51+
52+
EXEC tSQLt.AssertEqualsTable '#TestOutput', 'SqlUtils.tSQLt.CaptureOutputLog'
2153
END
2254
GO
2355

0 commit comments

Comments
 (0)