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


How to avoid this T-SQL statement affecting my TempDB?


How to avoid this T-SQL statement affecting my TempDB?

Author
Message
Charmer
Charmer
Hall of Fame
Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)

Group: General Forum Members
Points: 3192 Visits: 1062
WITH CTE AS (SELECT DISTINCT 
LTRIM(RTRIM(P.IncidentIDRef)) AS MODIDREF, P.JurisID, P.EntDttm AS CREATEDDTTM, P.DIDCU AS CREATEDPFIDREF, 'INC' AS MODCODE, 'C' RECTYPE,
REPLACE(STUFF
((SELECT '</P>' + C.FDNARR
FROM PSFDOC C
WHERE C.FDDOC# = T .FDDOC#
ORDER BY C.FDDOC#, C.FDLINE FOR XML PATH('')), 1, 10, ''), '</P>', '</P>') AS COMMENT
FROM PSFDOC T JOIN
PSDOCI P ON P.DIDOC# = T .FDDOC#
WHERE P.DIFILE = 'PLINCD' AND (NOT P.DIDESC IN ('cad system narrative', 'dispatch narrative')) AND P.DIDESC NOT LIKE 'Converted Cad Comment%')
SELECT *, CAST(CTE .COMMENT AS NVARCHAR(MAX)) AS COMMENT1, ROW_NUMBER() OVER (PARTITION BY CTE .JURISID, CTE .MODIDREF
ORDER BY CTE .JURISID, CTE .MODIDREF) - 1 AS SEQNO
FROM CTE



This SQL statement is affecting my Temp Db around 11 GB....Help me friends ...I need alternate SQL statement not to affect my temp db..
I have attached the estimated execution plan of this statement...If you need anything let me know please.
Give me suggestions please..

Thanks,
Charmer
Attachments
EXECUTIONPLAN.sqlplan (24 views, 58.00 KB)
GSquared
GSquared
SSC Guru
SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)

Group: General Forum Members
Points: 56581 Visits: 9730
The only way I see to possibly avoid tempdb on this one would be to build permanent tables, do the work in them that tempdb is doing in worktables, and use those instead of the CTE. But even that isn't likely to work, because the SQL engine will still need to do sorts on the data, for the distinct and row number operations at the very least, and that's usually done in tempdb.

If it's blowing tempdb up by 11 Gig, I'm assuming this query is dealing with a huge amount of data. Can you filter the data before-hand, in a separate table or query? That will still use tempdb, probably, but might use less of it.

- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
Charmer
Charmer
Hall of Fame
Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)

Group: General Forum Members
Points: 3192 Visits: 1062
GSquared (8/28/2012)
The only way I see to possibly avoid tempdb on this one would be to build permanent tables, do the work in them that tempdb is doing in worktables, and use those instead of the CTE. But even that isn't likely to work, because the SQL engine will still need to do sorts on the data, for the distinct and row number operations at the very least, and that's usually done in tempdb.

If it's blowing tempdb up by 11 Gig, I'm assuming this query is dealing with a huge amount of data. Can you filter the data before-hand, in a separate table or query? That will still use tempdb, probably, but might use less of it.


Yes you are absolutely correct. This table has records around 6 million...

ok GSquared, as you say let me filter the records in separate table and will work on it and i will let you know how things going on..

Thanks,
Charmer
Suresh B.
Suresh B.
SSCarpal Tunnel
SSCarpal Tunnel (4.9K reputation)SSCarpal Tunnel (4.9K reputation)SSCarpal Tunnel (4.9K reputation)SSCarpal Tunnel (4.9K reputation)SSCarpal Tunnel (4.9K reputation)SSCarpal Tunnel (4.9K reputation)SSCarpal Tunnel (4.9K reputation)SSCarpal Tunnel (4.9K reputation)

Group: General Forum Members
Points: 4878 Visits: 5329
Is "ORDER BY C.FDDOC#, C.FDLINE" required?

What is the type of C.FDLINE?

Creating an index on C.FDDOC#, C.FDLINE should imporve the tempdb size and execution time.
Charmer
Charmer
Hall of Fame
Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)

Group: General Forum Members
Points: 3192 Visits: 1062
Suresh B. (8/29/2012)
Is "ORDER BY C.FDDOC#, C.FDLINE" required?

What is the type of C.FDLINE?

Creating an index on C.FDDOC#, C.FDLINE should imporve the tempdb size and execution time.


Yes, order is must because concatenation is based on this order columns.

I have created a staging table and filtered the records as GSquared said.
Now, the performance is so good. but it still affects the temp db. But anyway i am happy:-) with the results since temp db is affected only about 700 MB where it was affected around 11 GB earlier.

Thanks,
Charmer
GSquared
GSquared
SSC Guru
SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)

Group: General Forum Members
Points: 56581 Visits: 9730
Glad we could help.

- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
Charmer
Charmer
Hall of Fame
Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)

Group: General Forum Members
Points: 3192 Visits: 1062
GSquared (8/29/2012)
Glad we could help.


Thank you so much, Pal...I really appreciate your suggestions

Thanks,
Charmer
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40662 Visits: 20000
Try putting the FOR XML PATH stringinator into a CROSS APPLY, where it can crunch up the rows of PSFDOC separately from the rest of the query. You might not even need the DISTINCT:

;WITH CTE AS (
SELECT --DISTINCT
LTRIM(RTRIM(P.IncidentIDRef)) AS MODIDREF,
P.JurisID,
P.EntDttm AS CREATEDDTTM,
P.DIDCU AS CREATEDPFIDREF,
'INC' AS MODCODE,
'C' RECTYPE,
x.Comment
FROM PSDOCI P
CROSS APPLY (
SELECT COMMENT = REPLACE(STUFF(
(SELECT '</P>' + C.FDNARR
FROM PSFDOC C
WHERE C.FDDOC# = P.DIDOC#
ORDER BY C.FDDOC#, C.FDLINE FOR XML PATH(''))
, 1, 10, ''), '</P>', '</P>')
) x
--JOIN PSFDOC T
--ON P.DIDOC# = T .FDDOC#
WHERE P.DIFILE = 'PLINCD'
AND (NOT P.DIDESC IN ('cad system narrative', 'dispatch narrative'))
AND P.DIDESC NOT LIKE 'Converted Cad Comment%'
)

SELECT
*,
CAST(CTE.COMMENT AS NVARCHAR(MAX)) AS COMMENT1,
ROW_NUMBER() OVER (PARTITION BY CTE .JURISID, CTE .MODIDREF ORDER BY CTE .JURISID, CTE .MODIDREF) - 1 AS SEQNO
FROM CTE



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Charmer
Charmer
Hall of Fame
Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)

Group: General Forum Members
Points: 3192 Visits: 1062
ChrisM@Work (8/29/2012)
Try putting the FOR XML PATH stringinator into a CROSS APPLY, where it can crunch up the rows of PSFDOC separately from the rest of the query. You might not even need the DISTINCT:

;WITH CTE AS (
SELECT --DISTINCT
LTRIM(RTRIM(P.IncidentIDRef)) AS MODIDREF,
P.JurisID,
P.EntDttm AS CREATEDDTTM,
P.DIDCU AS CREATEDPFIDREF,
'INC' AS MODCODE,
'C' RECTYPE,
x.Comment
FROM PSDOCI P
CROSS APPLY (
SELECT COMMENT = REPLACE(STUFF(
(SELECT '</P>' + C.FDNARR
FROM PSFDOC C
WHERE C.FDDOC# = P.DIDOC#
ORDER BY C.FDDOC#, C.FDLINE FOR XML PATH(''))
, 1, 10, ''), '</P>', '</P>')
) x
--JOIN PSFDOC T
--ON P.DIDOC# = T .FDDOC#
WHERE P.DIFILE = 'PLINCD'
AND (NOT P.DIDESC IN ('cad system narrative', 'dispatch narrative'))
AND P.DIDESC NOT LIKE 'Converted Cad Comment%'
)

SELECT
*,
CAST(CTE.COMMENT AS NVARCHAR(MAX)) AS COMMENT1,
ROW_NUMBER() OVER (PARTITION BY CTE .JURISID, CTE .MODIDREF ORDER BY CTE .JURISID, CTE .MODIDREF) - 1 AS SEQNO
FROM CTE



This one also works really great...Thank you Chris

Thanks,
Charmer
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40662 Visits: 20000
Thanks for the feedback. The original table had an unnecessary join which the new query eliminates, and if you can remove the DISTINCT now, then you remove a memory-hogging SORT too.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
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