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

Slow query Expand / Collapse
Is there a faster way to do what this query does?
Poll ResultsVotes
I do not have any answers to this question.
0%
0
Member Votes: 0, Anonymous Votes: 0. You don't have permission to vote within this poll.
Author
Message
Posted Wednesday, August 29, 2012 1:35 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, December 13, 2012 6:51 AM
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?
Post #1351437
Posted Wednesday, August 29, 2012 1:51 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, September 23, 2014 2:53 AM
Points: 1,101, Visits: 5,290
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.
Post #1351447
Posted Wednesday, August 29, 2012 2:22 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 10:25 AM
Points: 40,385, Visits: 36,827
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 2008, MVP
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

Post #1351466
Posted Wednesday, August 29, 2012 2:49 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:38 AM
Points: 6,861, Visits: 14,160
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
Post #1351475
Posted Wednesday, August 29, 2012 2:56 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, December 13, 2012 6:51 AM
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!
Post #1351481
Posted Wednesday, August 29, 2012 3:05 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: 2 days ago @ 7:58 PM
Points: 3,422, Visits: 5,366
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!
Post #1351482
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse