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


comparison in the merge statement about null values


comparison in the merge statement about null values

Author
Message
Evil Kraig F
Evil Kraig F
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20109 Visits: 7660
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
sqlfriends
sqlfriends
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10121 Visits: 4195
If I simplize my question, any alternative to use <> to compare columns with null values?
Evil Kraig F
Evil Kraig F
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20109 Visits: 7660
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
sqlfriends
sqlfriends
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10121 Visits: 4195
Ok. thanks.
Paul White
Paul White
SSC-Dedicated
SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)

Group: General Forum Members
Points: 34798 Visits: 11359
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
SQLPerformance.com
SQLblog.com
@SQL_Kiwi
Evil Kraig F
Evil Kraig F
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20109 Visits: 7660
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
Paul White
Paul White
SSC-Dedicated
SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)SSC-Dedicated (34K reputation)

Group: General Forum Members
Points: 34798 Visits: 11359
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
SQLPerformance.com
SQLblog.com
@SQL_Kiwi
Evil Kraig F
Evil Kraig F
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20109 Visits: 7660
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? Blush

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
Sean Lange
Sean Lange
SSC Guru
SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)

Group: General Forum Members
Points: 61193 Visits: 17954
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 Modens 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)
sqlfriends
sqlfriends
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10121 Visits: 4195
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,
....
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