x

Results of Sql to a Variable

I have a financial query that uses Sum() multiple times in different calculations. The query is very slow because the sum() function has to rerun multiple times in the query. Is there a way to store the results in a variable and reference the variable later in the query rather that redoing the sum() again? Query follows:

 /************************************************************************************
 Name:             Case Type Balance Report
 Date Created:     1/12/2011
 Created By:          Mike Gee    
 Purpose:          To report financial info for each case type. 
 Modifications:    mm/dd/yyyy - [Name] - [Description]
 
 ************************************************************************************/
 DECLARE @NetAmt money;  --I would like to load results to a variable like this...
 
 SELECT      fc.CASE_NUMBER 
  ,fc.CASE_CATEGORY_TYP_CD
  ,AFM_V_COST_DETAILS.COST_TYP_DESC
 
  ,(Select IsNull(SUM(CREDIT),0) 
                 From afm_v_cost_details cd2
                 where ID = 'RV' 
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) as 'TOTAL VOIDS (CODE=RV)'
     
 
  ,(Select IsNull(SUM(DEBIT),0) 
                 From afm_v_cost_details cd2
                 where ID = 'RP' 
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) as 'AMOUNT PAID (CODE=RP)'
     
 
  ,(Select IsNull(SUM(CREDIT),0) 
                 From afm_v_cost_details cd2
                 where ID = 'RV' 
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) -
                 (Select IsNull(SUM(DEBIT),0) * -1
                 From afm_v_cost_details cd2
                 where ID = 'RP' 
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) as 'NET AMOUNT'
     
 
 ,(Select IsNull(SUM(CREDIT),0) --assessments 
                 From afm_v_cost_details cd2
                 where ID = 'RC' 
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) as 'RECEIVABLE ASSESSMENTS (CODE=RC)'
     
 
                 
 ,(Select IsNull(SUM(DEBIT),0) --RECEIVABLE VOIDS/ADJUSTMENTS
                 From afm_v_cost_details cd2
                 where ID in('CV','CA') 
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) as 'TOTAL RECEIVABLE VOIDS/ADJUSTMENTS (CODES=CV,CA)'
     
 
 ,(Select IsNull(SUM(CREDIT),0) 
                 From afm_v_cost_details cd2
                 where ID = 'RC' 
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) -
                 (Select IsNull(SUM(DEBIT),0) * -1
                 From afm_v_cost_details cd2
                 where ID in('CV','CA')
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) as 'NET ASSESSMENTS (CODE RC - CV,CA)'
     
 
         
 ,(Select IsNull(SUM(CREDIT),0) 
                 From afm_v_cost_details cd2
                 where ID = 'RC' 
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) -
                 (Select IsNull(SUM(DEBIT),0) * -1
                 From afm_v_cost_details cd2
                 where ID in('CV','CA')
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) +
                 (Select IsNull(SUM(CREDIT),0) 
                 From afm_v_cost_details cd2
                 where ID = 'RV' 
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) -
                 (Select IsNull(SUM(DEBIT),0) * -1
                 From afm_v_cost_details cd2
                 where ID = 'RP' 
                 AND  (cd2.COST_TYP_DESC = 'PROBATION') 
                 and cd2.case_number = fc.case_number ) as 'BALANCE = (NET ASSESSMENTS - NET AMOUNT)'
     
 
                 
 FROM         dbo.AFM_V_COST_DETAILS INNER JOIN
              dbo.ACM_FACTS_CASE fc 
              ON dbo.AFM_V_COST_DETAILS.CASE_ID = fc.CASE_ID
     
 
 WHERE     (dbo.AFM_V_COST_DETAILS.COST_TYP_DESC IN(@CostTypeCd)) -- use "PROBATION" for JV 
             AND (fc.CASE_CATEGORY_TYP_CD IN(@CaseType)) 
     
 
  
 GROUP BY fc.CASE_NUMBER,fc.CASE_CATEGORY_TYP_CD,AFM_V_COST_DETAILS.COST_TYP_DESC
 
 ORDER BY fc.CASE_CATEGORY_TYP_CD, AFM_V_COST_DETAILS.COST_TYP_DESC, fc.CASE_NUMBER
more ▼

asked Jan 13, 2011 at 07:55 AM in Default

avatar image

mgee16
11 1 1 1

(comments are locked)
10|1200 characters needed characters left

2 answers: sort voted first

The query is probably slow because of the number of sub-queries, not merely the repetition of the SUM().

I've only had a quick glance at the query, but if you can't change some of the sub-selects into joins, then either a derived table or cte is your way forward, however that will probably just make it more readable, not necessarily any quicker.

edit : a quick rehash, but may contain some typos, as I've no real tables to test against

 select 
     fc.CASE_NUMBER ,fc.CASE_CATEGORY_TYP_CD ,AFM_V_COST_DETAILS.COST_TYP_DESC,
     [TOTAL VOIDS (CODE=RV)] as 'TOTAL VOIDS (CODE=RV)',
     [AMOUNT PAID (CODE=RP)] as 'TOTAL VOIDS (CODE=RP)',
     [TOTAL VOIDS (CODE=RV)] 
     + 
     [AMOUNT PAID (CODE=RP)] as 'NET AMOUNT',
     [RECEIVABLE ASSESSMENTS (CODE=RC)] as 'RECEIVABLE ASSESSMENTS (CODE=RC)',
     [TOTAL RECEIVABLE VOIDS/ADJUSTMENTS (CODES=CV,CA)] as 'TOTAL RECEIVABLE VOIDS/ADJUSTMENTS (CODES=CV,CA)',
     [RECEIVABLE ASSESSMENTS (CODE=RC)] 
     + 
     [TOTAL RECEIVABLE VOIDS/ADJUSTMENTS (CODES=CV,CA)] as 'NET ASSESSMENTS (CODE RC - CV,CA)',
     [RECEIVABLE ASSESSMENTS (CODE=RC)]
     +
     [TOTAL RECEIVABLE VOIDS/ADJUSTMENTS (CODES=CV,CA)]
     +
     [AMOUNT PAID (CODE=RP)]
     +
     [TOTAL VOIDS (CODE=RV)] as 'BALANCE = (NET ASSESSMENTS - NET AMOUNT)'
     
     
 
 FROM 
     dbo.AFM_V_COST_DETAILS 
     INNER JOIN dbo.ACM_FACTS_CASE fc ON dbo.AFM_V_COST_DETAILS.CASE_ID = fc.CASE_ID
     
     join (
         Select 
             case_number,
             IsNull(SUM(case when ID = 'RV' then CREDIT else 0 end),0) as 'TOTAL VOIDS (CODE=RV)',
             IsNull(SUM(case when ID = 'RP' then DEBIT else 0 end),0) as 'TOTAL VOIDS (CODE=RP)',
             IsNull(SUM(case when ID = 'RC' then CREDIT else 0 end),0) as 'RECEIVABLE ASSESSMENTS (CODE=RC)',
             IsNull(SUM(case when ID in('CV','CA') then DEBIT else 0 end),0) as 'TOTAL RECEIVABLE VOIDS/ADJUSTMENTS (CODES=CV,CA)'
         From afm_v_cost_details cd2 
         where
             cd2.COST_TYP_DESC = 'PROBATION'
         ) some_meaningful_name
     on some_meaningful_name.case_number = fc.case_number
 WHERE 
     (dbo.AFM_V_COST_DETAILS.COST_TYP_DESC IN(@CostTypeCd)) -- use "PROBATION" for JV 
 AND (fc.CASE_CATEGORY_TYP_CD IN(@CaseType))
 
 
 ORDER BY 
     fc.CASE_CATEGORY_TYP_CD, 
     AFM_V_COST_DETAILS.COST_TYP_DESC, 
     fc.CASE_NUMBER


What this is demonstrating, is that the base values are calculated only once, and then referenced by their aliases in the outer queries.

more ▼

answered Jan 13, 2011 at 08:26 AM

avatar image

Kev Riley ♦♦
64k 48 61 81

(comments are locked)
10|1200 characters needed characters left

You can use tables variables, temp tables, common table expresions aka cte'. A lot of flexibility depending upon a lot of factors.

It seems from a quick look at your question that youi're looking for table variables though.

more ▼

answered Jan 13, 2011 at 07:59 AM

avatar image

Slick84
1.3k 75 104 147

(comments are locked)
10|1200 characters needed characters left
Your answer
toggle preview:

Up to 2 attachments (including images) can be used with a maximum of 524.3 kB each and 1.0 MB total.

Follow this question

By Email:

Once you sign in you will be able to subscribe for any updates here

By RSS:

Answers

Answers and Comments

SQL Server Central

Need long-form SQL discussion? SQLserverCentral.com is the place.

Topics:

x32

asked: Jan 13, 2011 at 07:55 AM

Seen: 1108 times

Last Updated: Jan 14, 2011 at 07:49 AM

Copyright 2016 Redgate Software. Privacy Policy