SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


high cpu


high cpu

Author
Message
pmadhavapeddi22
pmadhavapeddi22
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1514 Visits: 1870
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 )
GilaMonster
GilaMonster
SSC Guru
SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)

Group: General Forum Members
Points: 86840 Visits: 45257
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, 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


Grant Fritchey
Grant Fritchey
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39480 Visits: 32630
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 Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
Kurt W. Zimmerman
Kurt W. Zimmerman
Ten Centuries
Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)

Group: General Forum Members
Points: 1382 Visits: 1398
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
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85384 Visits: 41078
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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
pmadhavapeddi22
pmadhavapeddi22
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1514 Visits: 1870
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))


Kurt W. Zimmerman
Kurt W. Zimmerman
Ten Centuries
Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)

Group: General Forum Members
Points: 1382 Visits: 1398
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
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85384 Visits: 41078
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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
SQLRNNR
SQLRNNR
SSC-Dedicated
SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)

Group: General Forum Members
Points: 32104 Visits: 18551
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, MVP


SQL RNNR

Posting Performance Based Questions - Gail Shaw

Grant Fritchey
Grant Fritchey
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39480 Visits: 32630
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 Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
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