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

Simple query maxing CPU Expand / Collapse
Author
Message
Posted Tuesday, October 22, 2013 3:47 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Friday, June 13, 2014 12:30 PM
Points: 205, Visits: 158
Good afternoon everyone,

I've got a simple query that should be no problem at all but which maxes out the CPU and causes the server to lock up. Here's the query:
;WITH e_Dupe AS
(
SELECT mcrn
,mpidm
FROM Registration_loaderr
GROUP BY mcrn, mpidm
HAVING COUNT(*) > 1
)
SELECT *
FROM Registration_loaderr le
INNER JOIN e_Dupe ed
ON le.mcrn = ed.mcrn
AND le.mpidm = ed.mpidm
WHERE le.error_check = '142285'

The table definition is:
CREATE TABLE [dbo].[Registration_loaderr]
(
[mcrn] [varchar](41) NULL,
[mpidm] [int] NULL,
[credit_hrs] [numeric](6, 0) NULL,
[grade_alpha] [varchar](25) NULL,
[grade_numeric] [numeric](5, 2) NULL,
[grade_numeric_possible] [numeric](5, 2) NULL,
[credits_earned] [numeric](5, 2) NULL,
[GPA_Credits] [numeric](5, 2) NULL,
[GPA_QP] [numeric](5, 2) NULL,
[Early_College] [char](1) NULL,
[Dual_Credit] [char](1) NULL,
[Error_check] [varchar](50) NULL,
[D_Acad_yr] [char](7) NULL,
[D_TERM] [char](3) NULL,
[D_IPEDS] [int] NULL,
[D_CRN] [char](6) NULL
) ON [PRIMARY]
GO

As this table is for staging ETL data there are no indexes. There are roughly 900k rows in the table and the given query should return 0 records. If the CTE is excluded the query runs in 2 seconds returning ~122k records. All records have non-null Mcrn and Mpidm values. The CTE returns zero rows. Other simple queries hitting this table cause the same CPU issue. In the past the simple queries ran with zero issues but suddenly they max the CPU. The only recent change has been the addition of 4 persisted, calculated columns. I removed the columns and the issue persists. Attached is the execution plan.

I don't believe this is a T-SQL issue, I think something is wrong with the table. Any suggestions on what issues I should look for?


  Post Attachments 
SimpleQueryExPlan.sqlplan (10 views, 53.21 KB)
Post #1507399
Posted Wednesday, October 23, 2013 2:50 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: Today @ 5:09 AM
Points: 971, Visits: 3,009
What do these give you?

USE [OSBE_ILEADS];
GO

EXEC sp_spaceused Registration_loaderr;

USE [OSBE_ILEADS];
GO

SELECT index_id, avg_fragmentation_in_percent, page_count, avg_page_space_used_in_percent FROM sys.dm_db_index_physical_stats(DB_ID(), OBJECT_ID('Registration_loaderr'), NULL, NULL, 'SAMPLED');





The SQL Guy @ blogspot

@SeanPearceSQL

About Me
Post #1507502
Posted Wednesday, October 23, 2013 12:54 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Friday, June 13, 2014 12:30 PM
Points: 205, Visits: 158
Here are the results from the those two queries:

name                  	rows    	reserved    	data          	index_size 	unused
Registration_loaderr 881866 266888 KB 250784 KB 8 KB 16096 KB


index_id	avg_fragmentation_in_percent	page_count	avg_page_space_used_in_percent
0 0 31300 49.3581912527798
Post #1507798
Posted Thursday, October 24, 2013 1:01 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: Today @ 5:09 AM
Points: 971, Visits: 3,009
Hi,

Your pages are only using 49% of the available space. This is a particular behaviour of heaps that have frequent deletes. I have blogged about this behaviour.

Heaps of Trouble

Try build a clustered index on the table and see if that improves your query time.





The SQL Guy @ blogspot

@SeanPearceSQL

About Me
Post #1507898
Posted Thursday, October 24, 2013 4:25 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Wednesday, November 19, 2014 5:03 AM
Points: 2,840, Visits: 3,975
INdexes is definitely a MUST thing here or everywhere .

other thing can below will return the same data too ?

;WITH e_Dupe AS
(
SELECT mcrn
,mpidm
FROM Registration_loaderr
WHERE error_check = '142285'
GROUP BY mcrn, mpidm
HAVING COUNT(*) > 1
)
SELECT *
FROM Registration_loaderr le
INNER JOIN e_Dupe ed
ON le.mcrn = ed.mcrn
AND le.mpidm = ed.mpidm



-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done
Post #1507957
Posted Thursday, October 24, 2013 8:16 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Friday, June 13, 2014 12:30 PM
Points: 205, Visits: 158
Adding a clustered index fixed it. After adding the clustered index on those two columns the query returns in 0 seconds. Here are the new results from those two queries:

name            	rows    	reserved	data    	index_size	unused
Registration_loaderr 881866 93704 KB 92392 KB 656 KB 656 KB

index_id avg_fragmentation_in_percent page_count avg_page_space_used_in_percent
1 0.0606113083383843 11549 99.2834198171485


Notice the table went from 266M to 93M and the page count went from 31k to 11k. I didn't know heaps reacted that way to a delete statement. It's really good to know, thank you.

Bhuvnesh, that would certainly return the same results and would probably be a better way of writing the query.

Thank you both for your help! It's greatly appreciated!
Post #1508074
Posted Thursday, October 24, 2013 8:28 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: Today @ 5:09 AM
Points: 971, Visits: 3,009
ElijahE (10/24/2013)
Adding a clustered index fixed it.
Thank you both for your help! It's greatly appreciated!

You're welcome. I'm glad to assist.

ElijahE (10/24/2013)
Bhuvnesh, that would certainly return the same results and would probably be a better way of writing the query.


There is a logical difference between the two though.
Your query checks for rows duplicating mcrn & mpidm then returns any of those with an error_check of '142285'.
The second query checks for rows duplicating mcrn & mpidm with an error_check of '142285'.
With the following data the results will be different:

DECLARE @T TABLE
([mcrn] [varchar](41) NULL,
[mpidm] [int] NULL,
[Error_check] [varchar](50) NULL);

INSERT INTO @T VALUES
('Row1', 1, '142285'),
('Row1', 1, '0'),
('Row1', 1, '0');





The SQL Guy @ blogspot

@SeanPearceSQL

About Me
Post #1508086
Posted Thursday, October 24, 2013 8:37 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Friday, June 13, 2014 12:30 PM
Points: 205, Visits: 158
The mcrn field is a grouping of multiple fields into one (not my design). The information stored in the error_check field is also included in the mcrn field. That's why the queries would return the same data in this specific case.
Post #1508093
Posted Friday, October 25, 2013 2:04 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Wednesday, November 19, 2014 5:03 AM
Points: 2,840, Visits: 3,975
ElijahE (10/24/2013)
Adding a clustered index fixed it. After adding the clustered index on those two columns the query returns in 0 seconds.
it will actually it must be . try to create indexes to support your quesries.


-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done
Post #1508360
Posted Friday, October 25, 2013 10:17 AM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Today @ 7:29 AM
Points: 35,554, Visits: 32,150
Bhuvnesh (10/24/2013)
INdexes is definitely a MUST thing here or everywhere .


Careful now... I'd have to say, "It Depends". There are quite a few places where adding an index is actually the worst thing you could do even for SELECTs.


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

(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 #1508522
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse