Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Execution Plan -- Clustered Index Update


Execution Plan -- Clustered Index Update

Author
Message
Bhuvnesh
Bhuvnesh
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2930 Visits: 4076
amarendra.sahoo (11/5/2012)
One of my query execution plan shows 'Clustered Index Update' @ a cost of 152%.
are you using any third party tool like sql sentry ?

-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
nikhil.satam
nikhil.satam
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
Points: 5 Visits: 50
I have a similar kind of issue with my Execution Plan showing as Clustered Index Update cost as 98%
Whereas in my Update query I am not even updating the Clustered Index/Primary key column.
I am just using the primary key column in the where clause for equating with the parameter value.

My update script is:
BEGIN TRAN

update [MM_TItemCurrentStock] set
[OpeningStock] = 0,
[InwardStock] = 0,
[OutwardStock] = 0,
[ClosingStock] = 0,
[OpeningRate] = 0,
[OpeningValue] = 0,
[InwardRate] = 0,
[InwardValue] = 0,
[OutwardRate] = 0,
[OutwardValue] = 0,
[ClosingRate] = 0,
[ClosingValue]= 0,
[DirectSaleStock]= 0,
[DirectSaleRate]= 0,
[DirectSaleValue]= 0,
[TransferStock]= 0,
[TransferRate]= 0,
[TransferValue]= 0
where (OrganizationUnitID = @LoginOrganizationUnitID)

COMMIT

Table MM_TItemCurrentStock has primary key constraint on columns: ItemID and OrganizationUnitID

Can anybody please help me to resolve this higher Clustered Index Update Cost issue. Thanks in advance!!
GilaMonster
GilaMonster
SSC-Forever
SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)

Group: General Forum Members
Points: 47351 Visits: 44392
You are updating the clustered index, as the clustered index *is* the table. All of the columns in the table are part of the clustered index (not the key, but in the index)

There's nothing at all wrong with a 98% cost for the clustered index update. The costs are percentages, they have to add to 100, so all that tells you is that the only part of the plan that has a significant cost is the clustered index scan.

Don't look just at the %. Is the query slow, that's got to be the first thing to check. Also, the goal of tuning is not to change percentages of operators in a plan. It's to make the query faster.


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


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