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 12»»

high cpu Expand / Collapse
Author
Message
Posted Thursday, December 19, 2013 11:52 PM
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Yesterday @ 7:00 AM
Points: 534, Visits: 776
Hi

I have one stored procedure which in turn executes 3 more sps in it.
All the 4 stored procedures just update the records of two tables. Every column is updated individually.(20 columns for each table)

But the rows in each table are above 2,00,000. So the cpu is almost touching 100% for 30 secs.

We have a job which executes this SP for every five minutes. So, cpu touches 100%
very frequently.

Please suggest me to avoid this 100% cpu utilization.

(let me know if you need any other information )
Post #1524880
Posted Friday, December 20, 2013 12:15 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 @ 2:47 AM
Points: 41,502, Visits: 34,418
Tune the procedure?

Optimise the queries, tune the indexes so that you reduce the CPU and time required for the procedure. Hard to offer anything more specific without seeing code, table defs and execution plans.



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 #1524885
Posted Friday, December 20, 2013 4:10 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 4:31 AM
Points: 14,788, Visits: 27,263
Grab a copy of my book down in my signature. It tells you all about tuning your queries.

----------------------------------------------------
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood..." Theodore Roosevelt
The Scary DBA
Author of: SQL Server 2012 Query Performance Tuning
SQL Server 2008 Query Performance Tuning Distilled
and
SQL Server Execution Plans

Product Evangelist for Red Gate Software
Post #1524922
Posted Friday, December 20, 2013 8:26 AM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: 2 days ago @ 9:02 AM
Points: 956, Visits: 1,273
It would also help by posting the DDL & the code in the Sprocs... Sometimes adding indexes & statistics to a series of tables is like putting lipstick on a pig, you still have a pig...

Depending on how the code was put together it may be necessary to re-engineer the code.


Kurt


Kurt W. Zimmerman
SR DBA
Lefrak Organization
New York, NY

http://www.linkedin.com/in/kurtwzimmerman
Post #1525015
Posted Wednesday, January 01, 2014 12:37 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 5:41 PM
Points: 35,944, Visits: 30,229
pmadhavapeddi22 (12/19/2013)
Hi

I have one stored procedure which in turn executes 3 more sps in it.
All the 4 stored procedures just update the records of two tables. Every column is updated individually.(20 columns for each table)

But the rows in each table are above 2,00,000. So the cpu is almost touching 100% for 30 secs.

We have a job which executes this SP for every five minutes. So, cpu touches 100%
very frequently.

Please suggest me to avoid this 100% cpu utilization.

(let me know if you need any other information )


Actually, this is a common problem caused by an illegal form of the UPDATE statement. Please post the UPDATE statements involved so I can see if they have that problem.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1526943
Posted Tuesday, February 11, 2014 6:11 AM
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Yesterday @ 7:00 AM
Points: 534, Visits: 776
Jeff,

Sorry for the late reply,

continuation of the above topic...

As you asked, the below is one of the update statements we are using in stored procedure



Update de_norm_buscard_attr
set fax=(select fax from view_a x
where x.contractid in ( select pcm_child.contract_id from table_a pcm
inner join table_b pra on pcm.pcm_role_id=pra.pra_role_id
INNER JOIN table_c y ON pra.p_phn_id=y.p_phn_id
inner join table_d pris on pcm.pcm_role_id = pris.parent_role_instance_id
inner join table_a pcm_child on pris.role_instance_id = pcm_child.pcm_role_id
where (y.lst_updt_dtm >=@lst_updt_tm OR pra.lst_updt_dtm >=@lst_updt_tm))
and x.contractid=de_norm_buscard_attr.contract_id)
where contract_id in ( select pcm_child.contract_id from table_a pcm
inner join table_b pra on pcm.pcm_role_id=pra.pra_role_id
INNER JOIN table_c y ON pra.p_phn_id=y.p_phn_id
inner join table_d pris on pcm.pcm_role_id = pris.parent_role_instance_id
inner join table_a pcm_child on pris.role_instance_id = pcm_child.pcm_role_id
where (y.lst_updt_dtm >=@lst_updt_tm OR pra.lst_updt_dtm >=@lst_updt_tm))



Post #1540160
Posted Tuesday, February 11, 2014 9:17 AM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: 2 days ago @ 9:02 AM
Points: 956, Visits: 1,273
It appears you are running the same query in 2 different where clauses. If I were to tackle this I'd consider restructuring the code so this result set:

select pcm_child.contract_id 
from table_a pcm inner join
table_b pra on pcm.pcm_role_id = pra.pra_role_id INNER JOIN
table_c y ON pra.p_phn_id = y.p_phn_id inner join
table_d pris on pcm.pcm_role_id = pris.parent_role_instance_id inner join
table_a pcm_child on pris.role_instance_id = pcm_child.pcm_role_id
where (y.lst_updt_dtm >= @lst_updt_tm
OR pra.lst_updt_dtm >= @lst_updt_tm))

so it is in either a CTE or an indexed temporary table. The other think to look at is the Execution Plan. Make sure your tables being joined are indexed and have updated statistics.

Kurt


Kurt W. Zimmerman
SR DBA
Lefrak Organization
New York, NY

http://www.linkedin.com/in/kurtwzimmerman
Post #1540275
Posted Tuesday, February 11, 2014 4:16 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 5:41 PM
Points: 35,944, Visits: 30,229
pmadhavapeddi22 (2/11/2014)
Jeff,

Sorry for the late reply,

continuation of the above topic...

As you asked, the below is one of the update statements we are using in stored procedure



Update de_norm_buscard_attr
set fax=(select fax from view_a x
where x.contractid in ( select pcm_child.contract_id from table_a pcm
inner join table_b pra on pcm.pcm_role_id=pra.pra_role_id
INNER JOIN table_c y ON pra.p_phn_id=y.p_phn_id
inner join table_d pris on pcm.pcm_role_id = pris.parent_role_instance_id
inner join table_a pcm_child on pris.role_instance_id = pcm_child.pcm_role_id
where (y.lst_updt_dtm >=@lst_updt_tm OR pra.lst_updt_dtm >=@lst_updt_tm))
and x.contractid=de_norm_buscard_attr.contract_id)
where contract_id in ( select pcm_child.contract_id from table_a pcm
inner join table_b pra on pcm.pcm_role_id=pra.pra_role_id
INNER JOIN table_c y ON pra.p_phn_id=y.p_phn_id
inner join table_d pris on pcm.pcm_role_id = pris.parent_role_instance_id
inner join table_a pcm_child on pris.role_instance_id = pcm_child.pcm_role_id
where (y.lst_updt_dtm >=@lst_updt_tm OR pra.lst_updt_dtm >=@lst_updt_tm))





I thought it was going to be something like that. It's actually an illegal form of update and, although it will sometimes work correctly, it will eat the face off of your server when it doesn't.

What's illegal about it is that you're updating a table based on a join and the table being updated isn't explicity named as a table in the FROM clause. You won't fine any examples in Books Online that does such a thing when a JOIN is present in an UPDATE.

Add the de_norm_buscard_attr table to the FROM clause, give it an alias, join it properly with the other table(s), and update the alias instead of the table.

To be sure, I've not checked your code for other problems. I was just looking for the "illegal update" problem which is slower than multple accidental Cartesian products.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1540487
Posted Tuesday, February 11, 2014 5:08 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 7:28 PM
Points: 20,453, Visits: 14,063
Jeff Moden (2/11/2014)
pmadhavapeddi22 (2/11/2014)
Jeff,

Sorry for the late reply,

continuation of the above topic...

As you asked, the below is one of the update statements we are using in stored procedure



Update de_norm_buscard_attr
set fax=(select fax from view_a x
where x.contractid in ( select pcm_child.contract_id from table_a pcm
inner join table_b pra on pcm.pcm_role_id=pra.pra_role_id
INNER JOIN table_c y ON pra.p_phn_id=y.p_phn_id
inner join table_d pris on pcm.pcm_role_id = pris.parent_role_instance_id
inner join table_a pcm_child on pris.role_instance_id = pcm_child.pcm_role_id
where (y.lst_updt_dtm >=@lst_updt_tm OR pra.lst_updt_dtm >=@lst_updt_tm))
and x.contractid=de_norm_buscard_attr.contract_id)
where contract_id in ( select pcm_child.contract_id from table_a pcm
inner join table_b pra on pcm.pcm_role_id=pra.pra_role_id
INNER JOIN table_c y ON pra.p_phn_id=y.p_phn_id
inner join table_d pris on pcm.pcm_role_id = pris.parent_role_instance_id
inner join table_a pcm_child on pris.role_instance_id = pcm_child.pcm_role_id
where (y.lst_updt_dtm >=@lst_updt_tm OR pra.lst_updt_dtm >=@lst_updt_tm))





I thought it was going to be something like that. It's actually an illegal form of update and, although it will sometimes work correctly, it will eat the face off of your server when it doesn't.

What's illegal about it is that you're updating a table based on a join and the table being updated isn't explicity named as a table in the FROM clause. You won't fine any examples in Books Online that does such a thing when a JOIN is present in an UPDATE.

Add the de_norm_buscard_attr table to the FROM clause, give it an alias, join it properly with the other table(s), and update the alias instead of the table.

To be sure, I've not checked your code for other problems. I was just looking for the "illegal update" problem which is slower than multple accidental Cartesian products.


nice find and explanation




Jason AKA CirqueDeSQLeil
I have given a name to my pain...
MCM SQL Server


SQL RNNR

Posting Performance Based Questions - Gail Shaw
Posting Data Etiquette - Jeff Moden
Hidden RBAR - Jeff Moden
VLFs and the Tran Log - Kimberly Tripp
Post #1540499
Posted Tuesday, February 11, 2014 5:32 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 4:31 AM
Points: 14,788, Visits: 27,263
SQLRNNR (2/11/2014)
Jeff Moden (2/11/2014)
pmadhavapeddi22 (2/11/2014)
Jeff,

Sorry for the late reply,

continuation of the above topic...

As you asked, the below is one of the update statements we are using in stored procedure



Update de_norm_buscard_attr
set fax=(select fax from view_a x
where x.contractid in ( select pcm_child.contract_id from table_a pcm
inner join table_b pra on pcm.pcm_role_id=pra.pra_role_id
INNER JOIN table_c y ON pra.p_phn_id=y.p_phn_id
inner join table_d pris on pcm.pcm_role_id = pris.parent_role_instance_id
inner join table_a pcm_child on pris.role_instance_id = pcm_child.pcm_role_id
where (y.lst_updt_dtm >=@lst_updt_tm OR pra.lst_updt_dtm >=@lst_updt_tm))
and x.contractid=de_norm_buscard_attr.contract_id)
where contract_id in ( select pcm_child.contract_id from table_a pcm
inner join table_b pra on pcm.pcm_role_id=pra.pra_role_id
INNER JOIN table_c y ON pra.p_phn_id=y.p_phn_id
inner join table_d pris on pcm.pcm_role_id = pris.parent_role_instance_id
inner join table_a pcm_child on pris.role_instance_id = pcm_child.pcm_role_id
where (y.lst_updt_dtm >=@lst_updt_tm OR pra.lst_updt_dtm >=@lst_updt_tm))





I thought it was going to be something like that. It's actually an illegal form of update and, although it will sometimes work correctly, it will eat the face off of your server when it doesn't.

What's illegal about it is that you're updating a table based on a join and the table being updated isn't explicity named as a table in the FROM clause. You won't fine any examples in Books Online that does such a thing when a JOIN is present in an UPDATE.

Add the de_norm_buscard_attr table to the FROM clause, give it an alias, join it properly with the other table(s), and update the alias instead of the table.

To be sure, I've not checked your code for other problems. I was just looking for the "illegal update" problem which is slower than multple accidental Cartesian products.


nice find and explanation


I was thinking exactly the same thing. I love watching smart people work.


----------------------------------------------------
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood..." Theodore Roosevelt
The Scary DBA
Author of: SQL Server 2012 Query Performance Tuning
SQL Server 2008 Query Performance Tuning Distilled
and
SQL Server Execution Plans

Product Evangelist for Red Gate Software
Post #1540503
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse