Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««12

Execution Plan -- Clustered Index Update Expand / Collapse
Author
Message
Posted Friday, November 9, 2012 4:15 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Tuesday, July 19, 2016 4:34 AM
Points: 2,850, Visits: 4,076
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
Post #1382942
Posted Monday, July 18, 2016 10:43 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: 2 days ago @ 3:15 AM
Points: 5, Visits: 47
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!!

Post #1802755
Posted Tuesday, July 19, 2016 2:02 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:18 AM
Points: 44,887, Visits: 42,888
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

Post #1802799
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse