Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««123»»

comparison in the merge statement about null values Expand / Collapse
Author
Message
Posted Wednesday, August 22, 2012 3:45 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 11:44 AM
Points: 6,236, Visits: 7,380
sqlfriends (8/22/2012)
Thanks, so I still cannot get a better improved solution?


Without query, underlying schema, and sqlplan? Nope. You've gone from general methodology to a particular solution's optimization. The general mechanism is sound, the implementation can hang you up. Need to see everything you're working with to make a more effective recommendation.



- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1348780
Posted Wednesday, August 22, 2012 3:49 PM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Monday, August 18, 2014 4:41 PM
Points: 1,770, Visits: 3,202
If I simplize my question, any alternative to use <> to compare columns with null values?
Post #1348783
Posted Wednesday, August 22, 2012 3:59 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 11:44 AM
Points: 6,236, Visits: 7,380
sqlfriends (8/22/2012)
If I simplize my question, any alternative to use <> to compare columns with null values?


Nope, compare them in a non-null version (using ISNULL), or build the incredibly painful where clause you initially described. Anything else is worse.



- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1348788
Posted Wednesday, August 22, 2012 4:03 PM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Monday, August 18, 2014 4:41 PM
Points: 1,770, Visits: 3,202
Ok. thanks.
Post #1348789
Posted Wednesday, August 22, 2012 4:31 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 9:31 AM
Points: 11,194, Visits: 11,137
sqlfriends (8/22/2012)
Because I have quite a few <> comparisons in my sql, ( in my post it is just a part of them), if I write something like :
Student.WithdrawDate <> esis.WithdrawDate
OR (student.WithdrawDate is NULL AND esis.WithdrawDate is NOT NULL)
OR (student.WithdrawDate is NOT NULL AND esis.withdrawdate is NULL)

It will get very long, is it an easier way to do it?

can I use isnull(student.mailingaddress,'')<>isnull(esis.mailingaddress,'')

There is a better, and easier way to do it using NOT EXISTS and INTERSECT. I describe the technique here: http://bit.ly/EqualityComparison

This handles NULLs correctly, means you don't have to find a 'magic value' to use with ISNULL or COALESCE, and is SARGable. The basic pattern is as follows, but please read the full blog post to make sure you understand how and why it works.

WHERE NOT EXISTS
(
SELECT
Student.SchoolID,
Student.GradeLevel,
Student.LegalName,
Student.WithdrawDate,
Student.SPEDFlag,
Student.MailingAddress
INTERSECT
SELECT
esis.SchoolID,
esis.GradeLevel,
esis.LegalName,
esis.WithdrawDate,
esis.SPEDFlag,
esis.MailingAddress
)

Listing the columns is easy in SSMS (drag them from the object explorer to the query pane). In the case where all columns are significant, you can also use the star syntax:

WHERE NOT EXISTS
(
SELECT
Student.*
INTERSECT
SELECT
esis.*
)





Paul White
SQL Server MVP
SQLblog.com
@SQL_Kiwi
Post #1348799
Posted Wednesday, August 22, 2012 5:34 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 11:44 AM
Points: 6,236, Visits: 7,380
SQL Kiwi (8/22/2012)

There is a better, and easier way to do it using NOT EXISTS and INTERSECT. I describe the technique here: http://bit.ly/EqualityComparison


That. Is. AWESOME.

I stand humbly corrected, thanks for bringing this to the table Paul. I believe I have a query (or 10) to mark for modification once we get out of 2k5. Thanks again!



- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1348807
Posted Wednesday, August 22, 2012 5:51 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 9:31 AM
Points: 11,194, Visits: 11,137
Evil Kraig F (8/22/2012)
I believe I have a query (or 10) to mark for modification once we get out of 2k5.

The NOT EXISTS...INTERSECT thing works in SQL Server 2005 of course. I guess you mean you are waiting for 2008 to use MERGE?




Paul White
SQL Server MVP
SQLblog.com
@SQL_Kiwi
Post #1348808
Posted Wednesday, August 22, 2012 6:00 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 11:44 AM
Points: 6,236, Visits: 7,380
SQL Kiwi (8/22/2012)
Evil Kraig F (8/22/2012)
I believe I have a query (or 10) to mark for modification once we get out of 2k5.

The NOT EXISTS...INTERSECT thing works in SQL Server 2005 of course. I guess you mean you are waiting for 2008 to use MERGE?


Um, yes?

Right, and now that I've thoroughly looked like I'm completely distracted today, time to go look at a few queries... *whistles as he walks away hoping noone notices...*



- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1348810
Posted Wednesday, August 22, 2012 8:53 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 3:13 PM
Points: 13,282, Visits: 12,116
Evil Kraig F (8/22/2012)
SQL Kiwi (8/22/2012)

There is a better, and easier way to do it using NOT EXISTS and INTERSECT. I describe the technique here: http://bit.ly/EqualityComparison


That. Is. AWESOME.

I stand humbly corrected, thanks for bringing this to the table Paul. I believe I have a query (or 10) to mark for modification once we get out of 2k5. Thanks again!


+1 that is super cool Paul!!!


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1348828
Posted Thursday, August 23, 2012 9:30 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Monday, August 18, 2014 4:41 PM
Points: 1,770, Visits: 3,202
SQL Kiwi (8/22/2012)
sqlfriends (8/22/2012)
Because I have quite a few <> comparisons in my sql, ( in my post it is just a part of them), if I write something like :
Student.WithdrawDate <> esis.WithdrawDate
OR (student.WithdrawDate is NULL AND esis.WithdrawDate is NOT NULL)
OR (student.WithdrawDate is NOT NULL AND esis.withdrawdate is NULL)

It will get very long, is it an easier way to do it?

can I use isnull(student.mailingaddress,'')<>isnull(esis.mailingaddress,'')

There is a better, and easier way to do it using NOT EXISTS and INTERSECT. I describe the technique here: http://bit.ly/EqualityComparison

This handles NULLs correctly, means you don't have to find a 'magic value' to use with ISNULL or COALESCE, and is SARGable. The basic pattern is as follows, but please read the full blog post to make sure you understand how and why it works.

WHERE NOT EXISTS
(
SELECT
Student.SchoolID,
Student.GradeLevel,
Student.LegalName,
Student.WithdrawDate,
Student.SPEDFlag,
Student.MailingAddress
INTERSECT
SELECT
esis.SchoolID,
esis.GradeLevel,
esis.LegalName,
esis.WithdrawDate,
esis.SPEDFlag,
esis.MailingAddress
)

Listing the columns is easy in SSMS (drag them from the object explorer to the query pane). In the case where all columns are significant, you can also use the star syntax:

WHERE NOT EXISTS
(
SELECT
Student.*
INTERSECT
SELECT
esis.*
)



Thanks Paul.

So in the merge statement,
Right below when matched statement I can add where not exists like below ? Thanks

When Matched

and WHERE NOT EXISTS (
SELECT
Student.SchoolID,
Student.GradeLevel,
Student.LegalName,
Student.WithdrawDate,
Student.SPEDFlag,
Student.MailingAddress
INTERSECT
SELECT
esis.SchoolID,
esis.GradeLevel,
esis.LegalName,
esis.WithdrawDate,
esis.SPEDFlag,
esis.MailingAddress
)[/Then update

Set Student.Schoolid=esis.schoolid,
....
Post #1349204
« Prev Topic | Next Topic »

Add to briefcase ««123»»

Permissions Expand / Collapse