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


Slow query


Slow query

Poll
Is there a faster way to do what this query does?

0% - 0 votes I do not have any answers to this question.
0% 0 votes
Member votes: 0, Guest votes: 0. You don't have permission to vote in this poll
Author
Message
hardus.lombaard
hardus.lombaard
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 17
update a
set a.Flag = 0
from table1 a
WHERE
a.OLD_NUMBER in (select number from table2) and
a.NEW_NUMBER not in (select number from table2)

The above query sets the flag column to 0 if OLD_NUMBER is found in table2 and NEW_NUMBER is not found in table2. The problem with this query is table2 has about 3,2 million numbers. The sub query "select number from table2" takes about 15-20 seconds to execute. This query therefore takes way to long (about 50 min if table1 has 6000 records). Is there a more efficient, faster way to accomplish the same?
Suresh B.
Suresh B.
SSCarpal Tunnel
SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)

Group: General Forum Members
Points: 4988 Visits: 5329
Try this (untested):
select * into #t
from table1

delete a
from #t a
inner join table2 b
on b.number = a.NEW_NUMBER

update a
set a.Flag = 0
from table1 a
inner join #t t
on t.NEW_NUMBER = b.NEW_NUMBER
inner join table2 b
on b.number = t.OLD_NUMBER



You need index on number column on table2.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)

Group: General Forum Members
Points: 224901 Visits: 46321
IN and NOT IN are usually very efficient, sometimes more so that joins. If the number column is nullable that could cause worse performance than expected.

Can you post the table definitions, index definitions and execution plan please?

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

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)

Group: General Forum Members
Points: 41555 Visits: 20005
hardus.lombaard (8/29/2012)
update a
set a.Flag = 0
from table1 a
WHERE
a.OLD_NUMBER in (select number from table2) and
a.NEW_NUMBER not in (select number from table2)

The above query sets the flag column to 0 if OLD_NUMBER is found in table2 and NEW_NUMBER is not found in table2. The problem with this query is table2 has about 3,2 million numbers. The sub query "select number from table2" takes about 15-20 seconds to execute. This query therefore takes way to long (about 50 min if table1 has 6000 records). Is there a more efficient, faster way to accomplish the same?


50 minutes suggests you don't have a usable index on column [number] of table2. With only 6000 rows in table1, indexing will matter far less.

Here's the simple join equivalent of your query;

UPDATE a
SET a.Flag = 0
FROM table1 a
INNER JOIN table2 t2a ON t2a.number = a.OLD_NUMBER
LEFT JOIN table2 t2b ON t2b.number = a.NEW_NUMBER
WHERE t2b.number IS NULL




“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
hardus.lombaard
hardus.lombaard
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 17
Your'e right. It actually doesn't matter whether I use joins or "in's" and "not in's". All I needed was an index!
dwain.c
dwain.c
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17849 Visits: 6431
You might want to try this one also:


UPDATE t
SET Flag = CASE (SELECT 1 FROM Table2 WHERE number = NEW_NUMBER) WHEN 1 THEN Flag ELSE 0 END
FROM Table1 t
INNER JOIN Table2 ON number = OLD_NUMBER





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
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