SQL Data Compare 8

Help for older versions available.

These pages cover SQL Data Compare 8, which is not the latest version. Help for other versions is also available.

Using a filter on a column on related (joined) tables

It can be useful to filter records by a column's relationship with a related table - but the "'WHERE clause" option in SQL Data Compare Project Configuration dialog box does not offer direct access to columns in two related tables. In this article we examine how a view can be used instead.

Consider two tables, Sales and LineItems. Lets say a record in LineItems belongs to a district in the Sales table. I want to only compare Lineitems records that belong in a certain district Suffolk, and ignore all the other districts.

To run the example, create two databases, TEST and TEST2. Both have these databases have tables LineItems, Sales and a view View_1:

  1. CREATE TABLE [dbo].[LineItems](
  2. [ID] [smallint] NOT NULL,
  3. [description] [nvarchar](50) NULL,
  4. [SalesID] [smallint] NULL,
  5. CONSTRAINT [PK_LineItems] PRIMARY KEY CLUSTERED
  6. (
  7. [ID] ASC
  8. )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
  9. ) ON [PRIMARY]
  10.  
  11.  
  12. CREATE TABLE [dbo].[Sales](
  13. [SalesID] [smallint] NOT NULL,
  14. [SalesDescription] [nvarchar](50) NULL,
  15. CONSTRAINT [PK_Sales] PRIMARY KEY CLUSTERED
  16. (
  17. [SalesID] ASC
  18. )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
  19. ) ON [PRIMARY]
  20.  
  21. Create VIEW VIEW_1 AS
  22. SELECT dbo.LineItems.ID, dbo.LineItems.description, dbo.LineItems.SalesID, dbo.Sales.SalesDescription
  23. FROM dbo.LineItems INNER JOIN
  24. dbo.Sales ON dbo.LineItems.SalesID = dbo.Sales.SalesID
  25. WHERE (dbo.Sales.SalesDescription = 'Suffolk')
  26.  
  27.  
  28. --Populate TEST with the following:
  29. INSERT INTO [dbo].[LineItems] ([ID], [description], [salesID]) VALUES (1, N'Fred ', 1)
  30. INSERT INTO [dbo].[LineItems] ([ID], [description], [salesID]) VALUES (2, N'Chrs ', 1)
  31. INSERT INTO [dbo].[LineItems] ([ID], [description], [salesID]) VALUES (3, N'Steve ', 1)
  32. INSERT INTO [dbo].[LineItems] ([ID], [description], [salesID]) VALUES (4, N'Greg ', 2)
  33. INSERT INTO [dbo].[LineItems] ([ID], [description], [salesID]) VALUES (5, N'Clare ', 2)
  34. INSERT INTO [dbo].[LineItems] ([ID], [description], [salesID]) VALUES (6, N'David ', 2)
  35. INSERT INTO [dbo].[LineItems] ([ID], [description], [salesID]) VALUES (7, N'Linda ', 3)
  36.  
  37. --And ...
  38. INSERT INTO [dbo].[Sales] ([SalesID], [SalesDescription]) VALUES (1, N'Norfolk')
  39. INSERT INTO [dbo].[Sales] ([SalesID], [SalesDescription]) VALUES (2, N'Suffolk')
  40. INSERT INTO [dbo].[Sales] ([SalesID], [SalesDescription]) VALUES (3, N'Hampshire')
  41. INSERT INTO [dbo].[Sales] ([SalesID], [SalesDescription]) VALUES (4, N'Essex')

Start SQL Data Compare and select the Include Views project option.

Sychronize TEST and TEST2. Now when clicking on VIEW_1 row the inserts created by the update script are:

  1. INSERT INTO [dbo].[View_1] ([ID], [salesID], [SalesDescription], [description]) VALUES (4, 2, N'Suffolk', N'Greg ')
  2. INSERT INTO [dbo].[View_1] ([ID], [salesID], [SalesDescription], [description]) VALUES (5, 2, N'Suffolk', N'Clare ')
  3. INSERT INTO [dbo].[View_1] ([ID], [salesID], [SalesDescription], [description]) VALUES (6, 2, N'Suffolk', N'David ')

We are limiting the update SQL script to only the Suffolk. In this way we can see how a simple view can control the comparison output by linking related tables.


Didn't find what you were looking for?