April 9, 2010 at 9:57 am
I am planning to do an update on a very large table (table1 ~250million). So need to know which one of the below query would be better & faster? Appreciate your reply. Both the fields from table1 are not indexed.
UPDATE a
SET a.field1 = b.field1
FROM table1 a (NOLOCK)
INNER JOIN table2 b (NOLOCK) ON a.id = b.id AND a.status = -1
(OR)
UPDATE a
SET a.field1 = b.field1
FROM table1 a (NOLOCK)
INNER JOIN table2 b (NOLOCK) ON a.id = b.id
WHERE a.status = -1
[font="Arial"]BASKAR BV
http://geekswithblogs.net/baskibv/Default.aspx
In life, as in football, you won’t go far unless you know where the goalposts are.[/font]
April 9, 2010 at 10:30 am
The two UPDATEs produce the exact same exec plan.
Just a few points:
1) NOLOCK has no effect on the table to update
2) NOLOCK can easily generate inconsistent data, get rid of it
3) Updating such a large table will make you log file explode. Do it in batches and back up the transaction log between batches, something like this
DECLARE @rows int
DECLARE @batchsize int
SET @rows = 1
SET @batchsize = 10000 -- whatever size you find appropriate
WHILE @rows > 0
BEGIN
UPDATE TOP(@batchsize) a
SET a.field1 = b.field1
FROM table1 a
INNER JOIN table2 b
ON a.id = b.id
WHERE a.status = -1
SET @rows = @@ROWCOUNT
BACKUP LOG ...
END
Obviously you would have to mark the rows already processed by the batch in order to avoid updating the same records over and over.
-- Gianluca Sartori
April 9, 2010 at 10:40 am
I think by just adding to the WHERE statement to Gianluca's fine example, you'd make sure you don't change fields where they already match, you'll prevent re-processing of the same rows...you might need to take nulls into account as well:
DECLARE @rows int
DECLARE @batchsize int
SET @rows = 1
SET @batchsize = 10000 -- whatever size you find appropriate
WHILE @rows > 0
BEGIN
UPDATE TOP(@batchsize) a
SET a.field1 = b.field1
FROM table1 a
INNER JOIN table2 b
ON a.id = b.id
WHERE a.status = -1
AND a.field1 != b.field1
--AND ISNULL(a.field1,'') != ISNULL(b.field1,'') --is there nulls?
SET @rows = @@ROWCOUNT
BACKUP LOG ...
END
Lowell
April 9, 2010 at 10:42 am
Thanks.
Eventhough table1 is very large, table2 would have less number of records around 3000 rows so i hope batch update is not required.
Also i am planning to add "date" condition to where clause from table1 to filter the number of records from table1 eventhough logically ID from table2 does not come below the date condition. Will that where clause help? "date" field has an non-clustered index in the table.
[font="Arial"]BASKAR BV
http://geekswithblogs.net/baskibv/Default.aspx
In life, as in football, you won’t go far unless you know where the goalposts are.[/font]
April 9, 2010 at 10:47 am
It depends. Compare the execution plans with and without date condition, you'll find out for sure.
If unsure, you could also try the performance of the two, changing UPDATE to SELECT.
If you could post tables and indexes script or attach the exec plan you would get better advice.
-- Gianluca Sartori
April 9, 2010 at 10:50 am
it might help...the devil is in the details.
the pseudo code example we have so far doesn't give us enough to work with...if the big table has an index on the datetime column, the WHERE statement might use an index to find the records, so it would be faster and lock less records (potentially) during the update. but depending on the number of records being updated, the optimizer might just decide it's easier for it to lock the whole table during the update; can't say for sure.
Baskar B.V (4/9/2010)
Thanks.Eventhough table1 is very large, table2 would have less number of records around 3000 rows so i hope batch update is not required.
Also i am planning to add "date" condition to where clause from table1 to filter the number of records from table1 eventhough logically ID from table2 does not come below the date condition. Will that where clause help? "date" field has an non-clustered index in the table.
Lowell
April 9, 2010 at 12:55 pm
This is the modified update statement based on your feedback...
UPDATE a
SET a.field1 = CASE WHEN b.field1 IS NOT NULL
THEN b.field1
ELSE a.field1
END
FROM table1 a
INNER JOIN table2 b ON a.id = b.id AND a.status = -1
where a.datekey > '20100101'
-- table is in primary filegroup and datekey clustered index under primary filegroup. After adding the where condition the clustered index scan on table1 become clustered index seek on table1 also reducing the cost from 98% to 3%. But the cost is now split to other components like hash join (34%).. earlier hash join is 1%.
But table2 clustered index seek is good since it is going to join with that big table.
Provide me if you can make some more suggestions.
volume of the tables:
table1 - 250million
table2 - 4000 records
[font="Arial"]BASKAR BV
http://geekswithblogs.net/baskibv/Default.aspx
In life, as in football, you won’t go far unless you know where the goalposts are.[/font]
April 9, 2010 at 12:59 pm
Forgot to mention in the previous post.
The total records which would get updated would be around 10 million records.
[font="Arial"]BASKAR BV
http://geekswithblogs.net/baskibv/Default.aspx
In life, as in football, you won’t go far unless you know where the goalposts are.[/font]
April 9, 2010 at 6:08 pm
How many of your records contain Nulls? Also, you may want to follow a suggestion that was put forth earlier and only update rows that are different. If there are a significant amount of Nulls or matches then you may see some improvement.
UPDATE a
SET a.field1 = b.field1
FROM table1 a
INNER JOIN table2 b ON a.id = b.id AND a.status = -1
where (a.datekey > '20100101') And (a.field1 != b.field1) And (b.field1 IS NOT NULL)
Go
April 9, 2010 at 6:39 pm
As K Cline pointed out, put the update field comparison in the WHERE clause instead of the in a CASE statement in the UPDATE. This allows the optimizer to potentially lessen the # of rows it needs to update. The CASE statement method will not help performance.
In regards to the cost values in your execution plan, optimizing a portion of a query will most times result in the costs being split out to other tasks. This is not always a bad thing. A query has to have 100% cost somewhere so just because one task is higher than some does not always mean it is not efficient. I like to base efficiency decisions more off of logical reads than the cost value in the query plan. Improving logical reads is a more accurate measure of how much a query has improved.
April 9, 2010 at 10:02 pm
Baskar B.V (4/9/2010)
Forgot to mention in the previous post.The total records which would get updated would be around 10 million records.
My recommendation is that you split that up into batches of about 2 million rows or less. Every system has a "tipping point" depending on a whole bunch of unpredictable factors. Depending on where the tipping point of your system is, it may only take 6-12 seconds to update 2 million rows but may take 10 hours to update 10 million rows in a single query.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply