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

Query execution time high cost? Expand / Collapse
Author
Message
Posted Wednesday, September 19, 2012 11:20 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Yesterday @ 8:55 PM
Points: 1,076, Visits: 3,054
Hi,

Is it possible to change alternative way to modified this sql statement. its tooks 2.47 min for fetching 151 records,

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO


Select JOBCODE,COMPLEXCODE,UNITCODE,GA_Drg_NO,
ISNULL(SUM(cast(b.item_wt as decimal(18,3))),0) as ItemWt,


(SELECT ISNULL(SUM(cast(isnull(c.item_wt,0) as decimal(18,3))),0)
FROM dbo.WR_Scope_GAD_Location_DynamicQuery as c
WHERE c.GA_Drg_NO = b.GA_Drg_NO
and c.JOBCODE=b.JOBCODE
and c.COMPLEXCODE=b.COMPLEXCODE
and c.UNITCODE=b.UNITCODE
--and c.Mark_No=b.Mark_No
and c.location='Shop' ) as 'fabscope_Shop',

(SELECT ISNULL(SUM(cast(isnull(c.item_wt,0) as decimal(18,3))),0)
FROM dbo.WR_Scope_GAD_Location_DynamicQuery as c
WHERE c.GA_Drg_NO = b.GA_Drg_NO
and c.JOBCODE=b.JOBCODE
and c.COMPLEXCODE=b.COMPLEXCODE
and c.UNITCODE=b.UNITCODE
--and c.Mark_No=b.Mark_No
and c.location='Site' ) as 'fabscope_Site',


(SELECT ISNULL(SUM(cast(isnull(c.itemwt,0) as decimal(18,3))),0)
FROM dbo.Redundant_qty_Locationwise_DynamicQuery as c
WHERE c.GA_Drg_NO = b.GA_Drg_NO
and c.JOBCODE=b.JOBCODE
and c.COMPLEXCODE=b.COMPLEXCODE
and c.UNITCODE=b.UNITCODE
--and c.Mark_No=b.Mark_No
and c.location='Shop' ) as 'Redqty_Shop',
(SELECT ISNULL(SUM(cast(isnull(c.itemwt,0) as decimal(18,3))),0)
FROM dbo.Redundant_qty_Locationwise_DynamicQuery as c
WHERE c.GA_Drg_NO = b.GA_Drg_NO
and c.JOBCODE=b.JOBCODE
and c.COMPLEXCODE=b.COMPLEXCODE
and c.UNITCODE=b.UNITCODE
--and c.Mark_No=b.Mark_No
and c.location='Site' ) as 'Redqty_Site',

(SELECT ISNULL(SUM(cast(isnull(d.itemwt,0) as decimal(18,3))),0)
FROM dbo.Refabrication_qty_Locationwise_DynamicQuery as d
WHERE d.GA_Drg_NO = b.GA_Drg_NO
and d.JOBCODE=b.JOBCODE
and d.COMPLEXCODE=b.COMPLEXCODE
and d.UNITCODE=b.UNITCODE
--and d.Mark_No=b.Mark_No
and d.location='Shop') as 'Rfabqty_Shop',

(SELECT ISNULL(SUM(cast(isnull(d.itemwt,0) as decimal(18,3))),0)
FROM dbo.Refabrication_qty_Locationwise_DynamicQuery as d
WHERE d.GA_Drg_NO = b.GA_Drg_NO
and d.JOBCODE=b.JOBCODE
and d.COMPLEXCODE=b.COMPLEXCODE
and d.UNITCODE=b.UNITCODE
--and d.Mark_No=b.Mark_No
and d.location='Site') as 'Rfabqty_Site',

(SELECT ISNULL(SUM(cast(isnull(e.item_wt,0) as decimal(18,3))),0)
FROM dbo.ModificationQty_DynamicQuery as e
WHERE e.GAD_NO = b.GA_Drg_NO
and e.JOBCODE=b.JOBCODE
and e.COMPLEXCODE=b.COMPLEXCODE
and e.UNITCODE=b.UNITCODE
--and e.Mark_No=b.Mark_No
and e.location='Shop' ) as 'Modqty_Shop',
(SELECT ISNULL(SUM(cast(isnull(e.item_wt,0) as decimal(18,3))),0)
FROM dbo.ModificationQty_DynamicQuery as e
WHERE e.GAD_NO = b.GA_Drg_NO
and e.JOBCODE=b.JOBCODE
and e.COMPLEXCODE=b.COMPLEXCODE
and e.UNITCODE=b.UNITCODE
--and e.Mark_No=b.Mark_No
and e.location='Site' ) as 'Modqty_Site',
(SELECT ISNULL(SUM(cast(isnull(f.[shop Dispatch Front],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Shop') as 'shop_Dispatch_Front',

(SELECT ISNULL(SUM(cast(isnull(f.[shop Dispatch Front],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
-- and f.Mark_No=b.Mark_No
and f.location='Site') as 'site_Dispatch_Front',

(SELECT ISNULL(SUM(cast(isnull(f.[shop Dispatch Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
-- and f.Mark_No=b.Mark_No
and f.location='Shop') as 'shop_Dispatch_Wt',
(SELECT ISNULL(SUM(cast(isnull(f.[shop Dispatch Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
-- and f.Mark_No=b.Mark_No
and f.location='Site') as 'site_Dispatch_Wt',
(SELECT ISNULL(SUM(cast(isnull(f.[shop Dispatch Balance],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
-- and f.Mark_No=b.Mark_No
and f.location='Shop' ) as 'shop_Dispatch_Balance',
(SELECT ISNULL(SUM(cast(isnull(f.[shop Dispatch Balance],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Site' ) as 'site_Dispatch_Balance',
(SELECT ISNULL(SUM(cast(isnull(f.[shop DPT Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Shop' ) as 'shop_DPT_Wt',

(SELECT ISNULL(SUM(cast(isnull(f.[shop DPT Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Site' ) as 'site_DPT_Wt',
(SELECT ISNULL(SUM(cast(isnull(f.[shop Laydown Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Shop') as 'shop_Laydown_Wt',

(SELECT ISNULL(SUM(cast(isnull(f.[shop Laydown Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Site') as 'site_Laydown_Wt',

(SELECT ISNULL(SUM(cast(isnull(f.[shop MPT Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
-- and f.Mark_No=b.Mark_No
and f.location='Shop' ) as 'shop_MPT_Wt',
(SELECT ISNULL(SUM(cast(isnull(f.[shop MPT Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Site' ) as 'site_MPT_Wt',
(SELECT ISNULL(SUM(cast(isnull(f.[shop NDE Completed],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Shop' ) as 'shop_NDE_Completed',
(SELECT ISNULL(SUM(cast(isnull(f.[shop NDE Completed],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Site' ) as 'site_NDE_Completed',
(SELECT ISNULL(SUM(cast(isnull(f.[shop RT Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Shop') as 'shop_RT_Wt',
(SELECT ISNULL(SUM(cast(isnull(f.[shop RT Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Site') as 'site_RT_Wt',
(SELECT ISNULL(SUM(cast(isnull(f.[shop UT Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
--and f.Mark_No=b.Mark_No
and f.location='Shop') as 'shop_UT_Wt',
(SELECT ISNULL(SUM(cast(isnull(f.[shop UT Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
-- and f.Mark_No=b.Mark_No
and f.location='Site') as 'site_UT_Wt',
(SELECT ISNULL(SUM(cast(isnull(g.[shop SP&P Scope],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
--and g.Mark_No=b.Mark_No
and g.location='Shop' ) as 'shop_SPP_Scope',

(SELECT ISNULL(SUM(cast(isnull(g.[shop SP&P Scope],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
-- and g.Mark_No=b.Mark_No
and g.location='Site' ) as 'site_SPP_Scope',

(SELECT ISNULL(SUM(cast(isnull(g.[shop SP&P Front],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
--and g.Mark_No=b.Mark_No
and g.location='Shop') as 'shop_SPP_Front',

(SELECT ISNULL(SUM(cast(isnull(g.[shop SP&P Front],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
--and g.Mark_No=b.Mark_No
and g.location='Site') as 'site_SPP_Front',

(SELECT ISNULL(SUM(cast(isnull(g.[shop SP&P Done],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
--and g.Mark_No=b.Mark_No
and g.location='Shop' ) as 'shop_SPP_Done',
(SELECT ISNULL(SUM(cast(isnull(g.[shop SP&P Done],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
--and g.Mark_No=b.Mark_No
and g.location='Site' ) as 'site_SPP_Done',

(SELECT ISNULL(SUM(cast(isnull(g.[shop SP&P Balance],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
--and g.Mark_No=b.Mark_No
and g.location='Shop') as 'shop_SPP_Balance',
(SELECT ISNULL(SUM(cast(isnull(g.[shop SP&P Balance],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
--and g.Mark_No=b.Mark_No
and g.location='Site') as 'site_SPP_Balance',
(SELECT ISNULL(SUM(cast(isnull(g.[shop Intermediate Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
--and g.Mark_No=b.Mark_No
and g.location='Shop') as 'shop_Intermediate_Wt',
(SELECT ISNULL(SUM(cast(isnull(g.[shop Intermediate Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
--and g.Mark_No=b.Mark_No
and g.location='Site') as 'site_Intermediate_Wt',
(SELECT ISNULL(SUM(cast(isnull(g.[shop Final Coat Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
--and g.Mark_No=b.Mark_No
and g.location='Shop') as 'shop_Final_Coat_Wt',

(SELECT ISNULL(SUM(cast(isnull(g.[shop Final Coat Wt],0) as decimal(18,3))),0)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
-- and g.Mark_No=b.Mark_No
and g.location='Site') as 'site_Final_Coat_Wt'

from WR_Scope_GAD_Location_DynamicQuery as b

group by b.JOBCODE,b.COMPLEXCODE,b.UNITCODE,b.GA_Drg_NO

GO


Post #1361739
Posted Thursday, September 20, 2012 1:41 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 @ 8:37 AM
Points: 40,596, Visits: 37,053
Please post table definitions, index definitions and execution plan, as per http://www.sqlservercentral.com/articles/SQLServerCentral/66909/


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 #1361773
Posted Thursday, September 20, 2012 4:15 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 9:11 PM
Points: 14,196, Visits: 28,522
I'm not sure how SQL Server is going to deal with all those correlated queries. I'd love to see the execution plan for this. Can you get the actual execution plan and post it?

Without specifics, I'll make this suggestion. You've got the same two queries over and over through the code there, just changing the SELECT list. What about consolidating all that down to a single two queries and then combine them. If you can't JOIN them together, then UNION them, but repeating the query over and over like that seems likely to give the optimizer fits. But, understand, I'm speculating on inadequate information.


----------------------------------------------------
"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
Post #1361838
Posted Friday, September 21, 2012 2:47 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, February 15, 2013 11:34 AM
Points: 4, Visits: 461
how about something like this:


select jobcode,
complexcode,
unitcode,
ga_drg_no,
isnull(sum(cast(b.item_wt as decimal(18,3))),0) as itmwt,
sum(cast case when c.location='Shop' then isnull(c.item_wt,0) else 0 end as decimal(18,3)) as fabscope_Shop,
sum(cast case when c.location='Site' then isnull(c.item_wt,0) else 0 end as decimal(18,3)) as fabscope_Site,
sum(cast case when c.location='Shop' then isnull(d.item_wt,0) else 0 end as decimal(18,3)) as Redqty_Shop,
sum(cast case when c.location='Site' then isnull(d.item_wt,0) else 0 end as decimal(18,3)) as Redqty_Site,
etc
from wr_scope_gad_location_dynamicQuery as b
left outer join wr_scope_gad_location_dynamicQuery as c
on c.ga_drg_no = b.ga_drg_no
and c.jobcode = b.jobcode
and c.complexcode = b.complexcode
and c.unitcode = b.unitcode
and c.location in ('Shop','Site')
left outer join redundant_qty_locationwise_dynamicQuery as d
on c.ga_drg_no = b.ga_drg_no
and c.jobcode = b.jobcode
and c.complexcode = b.complexcode
and c.unitcode = b.unitcode
and c.location in ('Shop','Site')
etc
group by b.jobcode, b.complexcode, b.unitcode, b.ga_drg_no
Post #1362998
Posted Saturday, September 22, 2012 7:51 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Friday, December 12, 2014 8:24 PM
Points: 1,945, Visits: 3,173
Client/server architectures do the display formatting in a presentation layer; you are doing it in the query. That is not just wrong but a good way to screw up the optimizer.

We now use COALESCE and not ISNULL, etC.

You put spaces in column names so they cannot be used in any ANSI/ISO language, data dictionary, etc; this is display formatting!

Think about how “COALESCE(SUM(CAST(COALESCE(G.shop_final_coat_wt, 0) AS DECIMAL(18,3))), 0)” will work. The SUM() drops NULLs, so why make them into zeroes. Why cast it to a new data type in the query? Let the presentation layers do the formatting. You had 38 of these nightmares in one query. I doubt I have done that many in entire systems for Fortune 1000 companies.

The attribute property “_dynamicquery” scares me. Is there dynamic SQL hidden in this somewhere?

What you have done is write a 1950's COBOL program in T-SQL, where each of the scalar sub-queries is a “PERFORM <paragraph name>” in a bad disguise. The alphabetic aliases are the tape drive names in an old IBM system. No spacing around = to space on the punch cards, etc.

You need to start over. We nee to see DDL.



Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1363185
Posted Monday, September 24, 2012 2:22 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 @ 7:24 AM
Points: 949, Visits: 2,616
Sorry misread, ignore post..... Caffine needs extra time to kick in on a monday morning.

_________________________________________________________________________
SSC Guide to Posting and Best Practices
Post #1363360
Posted Monday, September 24, 2012 4:21 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 2:14 AM
Points: 6,890, Visits: 14,253
ananda.murugesan (9/19/2012)
Hi,

Is it possible to change alternative way to modified this sql statement. its tooks 2.47 min for fetching 151 records,

...



There are several. Putting all those many many correlated subqueries into CROSS APPLY constructs is a good place to start;

SELECT 
b.JOBCODE,
b.COMPLEXCODE,
b.UNITCODE,
b.GA_Drg_NO,
ISNULL(SUM(cast(b.item_wt as decimal(18,3))),0) as ItemWt,
WR_Scope_GAD_Location.[fabscope_Site],
WR_Scope_GAD_Location.[fabscope_Shop],
Redundant_qty_Locationwise.*,
Refabrication_qty_Locationwise.*,
ModificationQty.*,
Shop_Fab_Shop.*,
Shop_Fab_Site.*,
Shop_Paint_Details_Shop.*,
Shop_Paint_Details_Site.*

FROM WR_Scope_GAD_Location_DynamicQuery as b

CROSS APPLY (
SELECT
[fabscope_Site] = SUM(CASE WHEN c.location='Site' THEN c.item_wt ELSE 0 END),
[fabscope_Shop] = SUM(CASE WHEN c.location='Shop' THEN c.item_wt ELSE 0 END)
FROM dbo.WR_Scope_GAD_Location_DynamicQuery as c
WHERE c.GA_Drg_NO = b.GA_Drg_NO
and c.JOBCODE=b.JOBCODE
and c.COMPLEXCODE=b.COMPLEXCODE
and c.UNITCODE=b.UNITCODE
) WR_Scope_GAD_Location

CROSS APPLY (
SELECT
[Redqty_Site] = SUM(CASE WHEN c.location='Site' THEN c.itemwt ELSE 0 END),
[Redqty_Shop] = SUM(CASE WHEN c.location='Shop' THEN c.itemwt ELSE 0 END)
FROM dbo.Redundant_qty_Locationwise_DynamicQuery as c
WHERE c.GA_Drg_NO = b.GA_Drg_NO
and c.JOBCODE=b.JOBCODE
and c.COMPLEXCODE=b.COMPLEXCODE
and c.UNITCODE=b.UNITCODE
) Redundant_qty_Locationwise

CROSS APPLY(
SELECT
[Rfabqty_Site] = SUM(CASE WHEN d.location='Site' THEN d.itemwt ELSE 0 END),
[Rfabqty_Shop] = SUM(CASE WHEN d.location='Shop' THEN d.itemwt ELSE 0 END)
FROM dbo.Refabrication_qty_Locationwise_DynamicQuery as d
WHERE d.GA_Drg_NO = b.GA_Drg_NO
and d.JOBCODE=b.JOBCODE
and d.COMPLEXCODE=b.COMPLEXCODE
and d.UNITCODE=b.UNITCODE
) Refabrication_qty_Locationwise

CROSS APPLY (
SELECT
[Modqty_Site] = SUM(CASE WHEN e.location='Site' THEN e.item_wt ELSE 0 END),
[Modqty_Shop] = SUM(CASE WHEN e.location='Shop' THEN e.item_wt ELSE 0 END)
FROM dbo.ModificationQty_DynamicQuery as e
WHERE e.GAD_NO = b.GA_Drg_NO
and e.JOBCODE=b.JOBCODE
and e.COMPLEXCODE=b.COMPLEXCODE
and e.UNITCODE=b.UNITCODE
) ModificationQty

CROSS APPLY (
SELECT
[shop_Dispatch_Front] = SUM(f.[shop Dispatch Front]),
[shop_Dispatch_Wt] = SUM(f.[shop Dispatch Wt]),
[shop_Dispatch_Balance] = SUM(f.[shop Dispatch Balance]),
[shop_DPT_Wt] = SUM(f.[shop DPT Wt]),
[shop_Laydown_Wt] = SUM(f.[shop Laydown Wt]),
[shop_MPT_Wt] = SUM(f.[shop MPT Wt]),
[shop_NDE_Completed] = SUM(f.[shop NDE Completed]),
[shop_RT_Wt] = SUM(f.[shop RT Wt]),
[shop_UT_Wt] = SUM(f.[shop UT Wt])
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
AND f.location = 'Shop'
) Shop_Fab_Shop

CROSS APPLY (
SELECT
[site_Dispatch_Front] = SUM(f.[shop Dispatch Front]),
[site_Dispatch_Wt] = SUM(f.[shop Dispatch Wt]),
[site_Dispatch_Balance] = SUM(f.[shop Dispatch Balance]),
[site_DPT_Wt] = SUM(f.[shop DPT Wt]),
[site_Laydown_Wt] = SUM(f.[shop Laydown Wt]),
[site_MPT_Wt] = SUM(f.[shop MPT Wt]),
[site_NDE_Completed] = SUM(f.[shop NDE Completed]),
[site_RT_Wt] = SUM(f.[shop RT Wt]),
[site_UT_Wt] = SUM(f.[shop UT Wt])
FROM dbo.Shop_Fab_DynamicQuery as f
WHERE f.GA_Drg_NO = b.GA_Drg_NO
and f.JOBCODE=b.JOBCODE
and f.COMPLEXCODE=b.COMPLEXCODE
and f.UNITCODE=b.UNITCODE
AND f.location = 'Site'
) Shop_Fab_Site

CROSS APPLY (
SELECT
[shop_SPP_Scope] = SUM(g.[shop SP&P Scope]),
[shop_SPP_Front] = SUM(g.[shop SP&P Front]),
[shop_SPP_Done] = SUM(g.[shop SP&P Done]),
[shop_SPP_Balance] = SUM(g.[shop SP&P Balance]),
[shop_Intermediate_Wt] = SUM(g.[shop Intermediate Wt]),
[shop_Final_Coat_Wt] = SUM(g.[shop Final Coat Wt])
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
AND g.location='Shop'
) Shop_Paint_Details_Shop

CROSS APPLY (
SELECT
[site_SPP_Scope] = SUM(CASE WHEN g.location='Site' THEN g.[shop SP&P Scope] ELSE 0 END),
[site_SPP_Front] = SUM(CASE WHEN g.location='Site' THEN g.[shop SP&P Front] ELSE 0 END),
[site_SPP_Done] = SUM(CASE WHEN g.location='Site' THEN g.[shop SP&P Done] ELSE 0 END),
[site_SPP_Balance] = SUM(CASE WHEN g.location='Site' THEN g.[shop SP&P Balance] ELSE 0 END),
[site_Intermediate_Wt] = SUM(CASE WHEN g.location='Site' THEN g.[shop Intermediate Wt] ELSE 0 END),
[site_Final_Coat_Wt] = SUM(CASE WHEN g.location='Site' THEN g.[shop Final Coat Wt] ELSE 0 END)
FROM dbo.Shop_Paint_Details_DynamicQuery as g
WHERE g.drawing_no = b.GA_Drg_NO
and g.JOBCODE=b.JOBCODE
and g.COMPLEXCODE=b.COMPLEXCODE
and g.UNITCODE=b.UNITCODE
AND g.location='Site'
) Shop_Paint_Details_Site

GROUP BY b.JOBCODE, b.COMPLEXCODE, b.UNITCODE, b.GA_Drg_NO



“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
Post #1363402
Posted Monday, September 24, 2012 4:42 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 2:14 AM
Points: 6,890, Visits: 14,253
Having made some sense of the mess, you can play with different ways of getting the same result;

-- note how 'shop' and 'site' can be distinguished either in the output or in the FROMlist.
-- in the output, using SUM(CASE WHEN gad.location='Site' THEN gad.item_wt ELSE 0 END) is likely
-- to be more efficient because the source table only has to be read once.
SELECT
b.JOBCODE,
b.COMPLEXCODE,
b.UNITCODE,
b.GA_Drg_NO,
ISNULL(SUM(cast(b.item_wt as decimal(18,3))),0) as ItemWt,

[fabscope_Site] = SUM(CASE WHEN gad.location='Site' THEN gad.item_wt ELSE 0 END),
[fabscope_Shop] = SUM(CASE WHEN gad.location='Shop' THEN gad.item_wt ELSE 0 END),

[Redqty_Site] = SUM(CASE WHEN red.location='Site' THEN red.itemwt ELSE 0 END),
[Redqty_Shop] = SUM(CASE WHEN red.location='Shop' THEN red.itemwt ELSE 0 END),

[Rfabqty_Site] = SUM(CASE WHEN refab.location='Site' THEN refab.itemwt ELSE 0 END),
[Rfabqty_Shop] = SUM(CASE WHEN refab.location='Shop' THEN refab.itemwt ELSE 0 END),

[Modqty_Site] = SUM(CASE WHEN modi.location='Site' THEN modi.item_wt ELSE 0 END),
[Modqty_Shop] = SUM(CASE WHEN modi.location='Shop' THEN modi.item_wt ELSE 0 END),

[shop_Dispatch_Front] = SUM(fabshop.[shop Dispatch Front]),
[shop_Dispatch_Wt] = SUM(fabshop.[shop Dispatch Wt]),
[shop_Dispatch_Balance] = SUM(fabshop.[shop Dispatch Balance]),
[shop_DPT_Wt] = SUM(fabshop.[shop DPT Wt]),
[shop_Laydown_Wt] = SUM(fabshop.[shop Laydown Wt]),
[shop_MPT_Wt] = SUM(fabshop.[shop MPT Wt]),
[shop_NDE_Completed] = SUM(fabshop.[shop NDE Completed]),
[shop_RT_Wt] = SUM(fabshop.[shop RT Wt]),
[shop_UT_Wt] = SUM(fabshop.[shop UT Wt]),

[site_Dispatch_Front] = SUM(fabsite.[shop Dispatch Front]),
[site_Dispatch_Wt] = SUM(fabsite.[shop Dispatch Wt]),
[site_Dispatch_Balance] = SUM(fabsite.[shop Dispatch Balance]),
[site_DPT_Wt] = SUM(fabsite.[shop DPT Wt]),
[site_Laydown_Wt] = SUM(fabsite.[shop Laydown Wt]),
[site_MPT_Wt] = SUM(fabsite.[shop MPT Wt]),
[site_NDE_Completed] = SUM(fabsite.[shop NDE Completed]),
[site_RT_Wt] = SUM(fabsite.[shop RT Wt]),
[site_UT_Wt] = SUM(fabsite.[shop UT Wt]),

[shop_SPP_Scope] = SUM(paintshop.[shop SP&P Scope]),
[shop_SPP_Front] = SUM(paintshop.[shop SP&P Front]),
[shop_SPP_Done] = SUM(paintshop.[shop SP&P Done]),
[shop_SPP_Balance] = SUM(paintshop.[shop SP&P Balance]),
[shop_Intermediate_Wt] = SUM(paintshop.[shop Intermediate Wt]),
[shop_Final_Coat_Wt] = SUM(paintshop.[shop Final Coat Wt]),

[Site_SPP_Scope] = SUM(paintsite.[shop SP&P Scope]),
[Site_SPP_Front] = SUM(paintsite.[shop SP&P Front]),
[Site_SPP_Done] = SUM(paintsite.[shop SP&P Done]),
[Site_SPP_Balance] = SUM(paintsite.[shop SP&P Balance]),
[Site_Intermediate_Wt] = SUM(paintsite.[shop Intermediate Wt]),
[Site_Final_Coat_Wt] = SUM(paintsite.[shop Final Coat Wt])

FROM WR_Scope_GAD_Location_DynamicQuery as b

LEFT JOIN dbo.WR_Scope_GAD_Location_DynamicQuery as gad
ON gad.GA_Drg_NO = b.GA_Drg_NO
and gad.JOBCODE=b.JOBCODE
and gad.COMPLEXCODE=b.COMPLEXCODE
and gad.UNITCODE=b.UNITCODE

LEFT JOIN dbo.Redundant_qty_Locationwise_DynamicQuery as red
ON red.GA_Drg_NO = b.GA_Drg_NO
and red.JOBCODE=b.JOBCODE
and red.COMPLEXCODE=b.COMPLEXCODE
and red.UNITCODE=b.UNITCODE

LEFT JOIN dbo.Refabrication_qty_Locationwise_DynamicQuery as refab
ON refab.GA_Drg_NO = b.GA_Drg_NO
and refab.JOBCODE=b.JOBCODE
and refab.COMPLEXCODE=b.COMPLEXCODE
and refab.UNITCODE=b.UNITCODE

LEFT JOIN dbo.ModificationQty_DynamicQuery as modi
ON modi.GAD_NO = b.GA_Drg_NO
and modi.JOBCODE=b.JOBCODE
and modi.COMPLEXCODE=b.COMPLEXCODE
and modi.UNITCODE=b.UNITCODE

LEFT JOIN dbo.Shop_Fab_DynamicQuery as fabshop
ON fabshop.GA_Drg_NO = b.GA_Drg_NO
and fabshop.JOBCODE=b.JOBCODE
and fabshop.COMPLEXCODE=b.COMPLEXCODE
and fabshop.UNITCODE=b.UNITCODE
AND fabshop.location = 'Shop'

LEFT JOIN dbo.Shop_Fab_DynamicQuery as fabsite
ON fabsite.GA_Drg_NO = b.GA_Drg_NO
and fabsite.JOBCODE=b.JOBCODE
and fabsite.COMPLEXCODE=b.COMPLEXCODE
and fabsite.UNITCODE=b.UNITCODE
AND fabsite.location = 'Site'

LEFT JOIN dbo.Shop_Paint_Details_DynamicQuery as paintshop
ON paintshop.drawing_no = b.GA_Drg_NO
and paintshop.JOBCODE=b.JOBCODE
and paintshop.COMPLEXCODE=b.COMPLEXCODE
and paintshop.UNITCODE=b.UNITCODE
AND paintshop.location = 'Shop'

LEFT JOIN dbo.Shop_Paint_Details_DynamicQuery as paintsite
ON paintsite.drawing_no = b.GA_Drg_NO
and paintsite.JOBCODE = b.JOBCODE
and paintsite.COMPLEXCODE = b.COMPLEXCODE
and paintsite.UNITCODE = b.UNITCODE
AND paintsite.location = 'Site'

GROUP BY b.JOBCODE, b.COMPLEXCODE, b.UNITCODE, b.GA_Drg_NO



“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
Post #1363407
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse