SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Using FULL JOINs to Compare Datasets


Using FULL JOINs to Compare Datasets

Author
Message
53280comma1
53280comma1
Old Hand
Old Hand (331 reputation)Old Hand (331 reputation)Old Hand (331 reputation)Old Hand (331 reputation)Old Hand (331 reputation)Old Hand (331 reputation)Old Hand (331 reputation)Old Hand (331 reputation)

Group: General Forum Members
Points: 331 Visits: 231
The other option of course is to build the tolerance into the cte that is then compared with intersect or except, as in the following pseudo code (i'm using a phone here, forgive me for not using the posted example tables)

With a as (
Select id , cast( randomnum as numeric(3,2) from table1
), b as (
Select id , cast( randomnum as numeric(3,2) from table2
)

Select * from a
Except
Select * from b
;
tom.w.brannon
tom.w.brannon
SSCommitted
SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)

Group: General Forum Members
Points: 1935 Visits: 1434
The calculation of the column
ISNULL(S.RandomNumber, 0) - ISNULL(D.RandomNumber, 0) AS RandomNumberDiff
requires some attention. It is important to choose a numeric value that is far from your threshold number or it will yeild incorrect results. For example if the RandomNumber value in one set is 0 and the key is missing in the other then the difference will calculate as 0, even though they actually are not equal. If no good dummy value is apparent then logic like the following is needed:

SELECT COALESCE(S.ID, D.ID) AS ID,
S.RandomNumber AS SrcRandomNumber,
D.RandomNumber AS DestRandomNumber,
S.RandomNumber - D.RandomNumber AS RandomNumberDiff
FROM SRC S
FULL JOIN DEST D ON S.ID = D.ID
WHERE ABS(S.RandomNumber - D.RandomNumber) > @Tolerance
or (S.RandomNumber is null and D.RandomNumber is not null)
or (S.RandomNumber is not null and D.RandomNumber is null);
Carla Wilson-484785
Carla Wilson-484785
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2292 Visits: 1951
tom.w.brannon (4/23/2013)
The calculation of the column
ISNULL(S.RandomNumber, 0) - ISNULL(D.RandomNumber, 0) AS RandomNumberDiff
requires some attention. It is important to choose a numeric value that is far from your threshold number or it will yeild incorrect results. For example if the RandomNumber value in one set is 0 and the key is missing in the other then the difference will calculate as 0, even though they actually are not equal. If no good dummy value is apparent then logic like the following is needed:

SELECT COALESCE(S.ID, D.ID) AS ID,
S.RandomNumber AS SrcRandomNumber,
D.RandomNumber AS DestRandomNumber,
S.RandomNumber - D.RandomNumber AS RandomNumberDiff
FROM SRC S
FULL JOIN DEST D ON S.ID = D.ID
WHERE ABS(S.RandomNumber - D.RandomNumber) > @Tolerance
or (S.RandomNumber is null and D.RandomNumber is not null)
or (S.RandomNumber is not null and D.RandomNumber is null);


+1 I actually prefer retaining the nulls, and testing for those conditions as well.
lunds007
lunds007
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 18
EXCEPT Shouldn't really be used when comparing tables with lots of columns. Investigating which fields are actually different will take more time than using the FULL OUTER JOIN with Where clause to filter on only non matched records. If your compare query has an added column to tell you which column(s) are not matching, then you won't spend time investigating which fields are different.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search