January 8, 2013 at 2:08 am
Does anybody know why the following
If Exists (Select *
From Inserted I
Join dbo.T_PaymentItemGroup PIG On PIG.PaymentItemGroupID = I.PaymentItemGroupID
Join ...)
Or Exists (Select *
From Inserted I
Join dbo.T_PaymentItem PAY On PAY.PaymentItemID = I.PaymentItemID
Join ...)
Begin
{Do something}
Goto TR_End
End
might take 10 minutes to run while this version
If Exists (Select *
From Inserted I
Join dbo.T_PaymentItemGroup PIG On PIG.PaymentItemGroupID = I.PaymentItemGroupID
Join ...)
Begin
{Do something}
Goto TR_End
End
If Exists (Select *
From Inserted I
Join dbo.T_PaymentItem PAY On PAY.PaymentItemID = I.PaymentItemID
Join ...)
Begin
{Do something}
Goto TR_End
End
completes in a few hundred ms? (The code is in a trigger and is being called when about 3500 records are being updated.)
The only thing I can think of is that, in the first version, SQL is spending (a lot of) time deciding which of the two "Exists (Select *" is going to be quicker to execute.
Is this a well known performance problem? Should we be banning "If Exists (Select ...) Or Exists (Select ...)"?
January 9, 2013 at 1:21 am
its happening because of OR usage in first query , yes it is well know performance glitch.
-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
January 9, 2013 at 1:34 am
Really? Do you have any links to further details? That would be very helpful.
January 9, 2013 at 2:51 am
There is not a well known performance glitch with OR. ORs in a where clause used to perform badly on SQL 2000 because the optimiser had few methods to run it (and people often don't index correctly for OR). The limitations with the optimiser are gone in SQL 2005 and above (but people still often don't index correctly for ORs)
Any chance you can post an execution plan for the first one? What is the wait type that the query has during those 10 minutes? The wait type will give us an idea what is causing the delay.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
January 9, 2013 at 3:00 am
julian.fletcher (1/9/2013)
Really? Do you have any links to further details? That would be very helpful.
sse this link http://sqlserverplanet.com/optimization/using-union-instead-of-or
-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
January 9, 2013 at 3:03 am
Bhuvnesh (1/9/2013)
julian.fletcher (1/9/2013)
Really? Do you have any links to further details? That would be very helpful.sse this link http://sqlserverplanet.com/optimization/using-union-instead-of-or
That's what I was talking about with SQL 2000 and prior optimiser limitations. It's for OR in a where clause (and to be honest, it's far less relevant since SQL 2005), not OR in an IF.
Oh, and as for those examples he gave in that blog post...
The one with the OR:
Table 'SalesOrderDetail'. Scan count 5, logical reads 10564, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
SQL Server Execution Times:
CPU time = 187 ms, elapsed time = 337 ms.
The one with the Union:
Table 'SalesOrderDetail'. Scan count 10, logical reads 19068, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table 'Worktable'. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
SQL Server Execution Times:
CPU time = 250 ms, elapsed time = 323 ms.
So the 'efficient' version with the UNION uses 60ms more CPU time and does 9000 more logical reads than the 'inefficient' version with the OR. Hmmmm.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
January 9, 2013 at 3:06 am
thanks gail
-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
January 9, 2013 at 3:10 am
Thanks for that. However, I'm not sure I understand its relevance. I haven't got an OR in a WHERE clause. What I'm comparing is
If A Or B
{Do something}
with
If A
{Do something}
If B
{Do something}
aren't I?
Execution plans and wait types would be a bit tricky to get as (inevitably) we only saw the problem on a client's production server.
January 9, 2013 at 5:47 am
Just wanted to point out that OR combines two conditions. As far as I know; it means that 'Expression A' and 'Expression B' are evaluated and then the OR operator is applied for evaluating the final result of the 'Expression A OR B'.
So,
IF A OR B
BEGIN
{do something}
END
is not the same as
IF A
BEGIN
{do something}
END
IF B
BEGIN
{do something}
END
January 9, 2013 at 6:40 am
Apologies. That should be comparing
If A Or B
{Do something}
with
If A
Begin
{Do something}
Goto EndIt
End
If B
{Do something}
EndIt:
January 9, 2013 at 6:42 am
In case you missed this...
GilaMonster (1/9/2013)
Any chance you can post an execution plan for the first one? What is the wait type that the query has during those 10 minutes? The wait type will give us an idea what is causing the delay.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
January 9, 2013 at 6:47 am
It has only been reported on a client's live server, so getting the execution plan would be tricky, the wait type less tricky. But I'm afraid I don't have either to hand immediately. We've been unable to reproduce it here, even with a restore of a backup of their database.
January 9, 2013 at 7:15 am
Unfortunately I would need to see more info to really help with this. It's not a standard or known problem with a well documented solution. Could be a million things.
For now, can you ask that client to run a full stats updates on any tables that those selects affect?
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
January 9, 2013 at 7:43 am
The client's database has a nightly maintenance job to reindex.
Really, I was just wondering if there was a well known reason why
If A Or B
{Something}
might be massively slow while
If A
{Something}
Else If B
{Something}
is lightning fast. Does SQL try to do something 'clever' with "If A Or B" that it can't do with "If A Else If B"? But if it's "just one of those (performance) things", so be it and thanks for your time!
January 9, 2013 at 7:51 am
julian.fletcher (1/9/2013)
The client's database has a nightly maintenance job to reindex.Really, I was just wondering if there was a well known reason why
If A Or B
{Something}
might be massively slow while
If A
{Something}
Else If B
{Something}
is lightning fast. Does SQL try to do something 'clever' with "If A Or B" that it can't do with "If A Else If B"? But if it's "just one of those (performance) things", so be it and thanks for your time!
I have a reason why: in the case of the SEPARATE executions, you have a VERY EFFICIENT PLAN that makes a hit (at least one row found) and it executes the "do something" code and then does the GOTO - thus COMPLETELY SKIPPING THE SECOND IF EXISTS CHECK. That second IF EXISTS has a HORRIBLY SLOW query plan that is being executed when you do the combined-check OR attempt in your first sample code. That query is NOT being "SHORT CIRCUITED" to not run in the EXISTS OR EXISTS scenario because the optimizer doesn't work that way. To my knowledge there are very few things that short-circuit in the optimizer/engine (CASE being one of them).
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
Viewing 15 posts - 1 through 15 (of 19 total)
You must be logged in to reply to this topic. Login to reply