high cpu

  • 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 )

  • 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
  • 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

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • 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

  • 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.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • 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))

  • 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

  • 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.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • 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[/url]
    Learn Extended Events

  • 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

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Jeff, Thank you so much for the help. I will correct the code

  • jeff,

    I have re written the query by joining the de norm table in from clause, but the no of

    reads and cpu are high with the new query. Old query is showing low cpu and less no of reads. I also executed DTA for any new indexes but it showed no recommendations

    Thanks

  • pmadhavapeddi22 (2/12/2014)


    jeff,

    I have re written the query by joining the de norm table in from clause, but the no of

    reads and cpu are high with the new query. Old query is showing low cpu and less no of reads. I also executed DTA for any new indexes but it showed no recommendations

    Thanks

    You can't trust the DTA. In fact, it misses lots and lots of tuning opportunities. Instead, read the execution plan of the query to understand the choices made by the optimizer in order to see where you might be able to influence those choices by restructuring your tables, your indexes, or, most of the time, your code.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • pmadhavapeddi22 (2/12/2014)


    jeff,

    I have re written the query by joining the de norm table in from clause, but the no of

    reads and cpu are high with the new query. Old query is showing low cpu and less no of reads. I also executed DTA for any new indexes but it showed no recommendations

    Thanks

    You were 100% cpu previously, so what does high mean now?

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • pmadhavapeddi22 (2/12/2014)


    jeff,

    I have re written the query by joining the de norm table in from clause, but the no of

    reads and cpu are high with the new query. Old query is showing low cpu and less no of reads. I also executed DTA for any new indexes but it showed no recommendations

    Thanks

    I have to admit that you have just confused the heck out of me. I thought you said you were at 100% before. Please post the same query you made changes to and let's have a look. You might have done the new join incorrectly.

    --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.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 15 posts - 1 through 15 (of 18 total)

You must be logged in to reply to this topic. Login to reply