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


Group By Help


Group By Help

Author
Message
JayWinter
JayWinter
SSC Rookie
SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)

Group: General Forum Members
Points: 49 Visits: 144
I have a script that uses the GROUP BY clause and returns the SUM much greater than expected. Here is the script with GROUP BY followed by the script without GROUP BY. The value returned by SUM(RETAIL_SALES.[Sales Units LW]) as [Sales Units LW] is 18426. The correct value should be 6142. I appreciate your help.

STYLE COLOR SEASON YR MO WK Sales Units LW
HK87202 FWHG 2012 2012 7 4 18426.00

STYLE COLOR SEASON YR MO WK Sales Units LW
HK87202 FWHG 2012 2012 7 4 366
HK87202 FWHG 2012 2012 7 4 796
HK87202 FWHG 2012 2012 7 4 1189
HK87202 FWHG 2012 2012 7 4 1814
HK87202 FWHG 2012 2012 7 4 1977
TOTAL 6142

SELECT DISTINCT
ITEMMAST.STYLE as STYLE
,ITEMMAST.COLOR as COLOR
,Max(ITEMMAST.SEASON) as SEASON
,RETAIL_SALES.YR
,RETAIL_SALES.MO
,RETAIL_SALES.WK
,SUM(RETAIL_SALES.[Sales Units LW]) as [Sales Units LW]

FROM Evy_RH_Objects.dbo.RETAIL_SALES RETAIL_SALES
LEFT OUTER JOIN RH2007_EvyLive.dbo.ITEMMAST ITEMMAST on ITEMMAST.CUSTNO='WALM01' and (ITEMMAST.SKU=RETAIL_SALES.SKU or ITEMMAST.ITEMUPC=RETAIL_SALES.SKU)

WHERE
RETAIL_SALES.CUST_NO='WALM01'
and RETAIL_SALES.WK=4
and ITEMMAST.STYLE='HK87202'

GROUP BY ITEMMAST.STYLE, ITEMMAST.COLOR, RETAIL_SALES.YR, RETAIL_SALES.MO, RETAIL_SALES.WK

=================================================================================
SELECT DISTINCT
ITEMMAST.STYLE as STYLE
,ITEMMAST.COLOR as COLOR
,ITEMMAST.SEASON as SEASON
,RETAIL_SALES.YR
,RETAIL_SALES.MO
,RETAIL_SALES.WK
,RETAIL_SALES.[Sales Units LW] as [Sales Units LW]

FROM Evy_RH_Objects.dbo.RETAIL_SALES RETAIL_SALES
LEFT OUTER JOIN RH2007_EvyLive.dbo.ITEMMAST ITEMMAST on ITEMMAST.CUSTNO='WALM01' and (ITEMMAST.SKU=RETAIL_SALES.SKU or ITEMMAST.ITEMUPC=RETAIL_SALES.SKU)

WHERE
RETAIL_SALES.CUST_NO='WALM01'
and RETAIL_SALES.WK=4
and ITEMMAST.STYLE='HK87202'
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)

Group: General Forum Members
Points: 87718 Visits: 41121
You may have a many-to-many join going on. You should probably also have things like "ITEMMAST.CUSTNO='WALM01'" in a WHERE clause instead of an ON especially when outer joins are involved.

--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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Phil Parkin
Phil Parkin
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18833 Visits: 20460
Following on from Jeff's comment - if you remove the GROUP BY, you should be able to check whether more rows are being returned than you expect/want.


Help us to help you. For better, quicker and more-focused answers to your questions, consider following the advice in this link.

If the answer to your question can be found with a brief Google search, please perform the search yourself, rather than expecting one of the SSC members to do it for you.

Please surround any code or links you post with the appropriate IFCode formatting tags. It helps readability a lot.
JayWinter
JayWinter
SSC Rookie
SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)SSC Rookie (49 reputation)

Group: General Forum Members
Points: 49 Visits: 144
I did remove the GROUP BY and and achieved the correct result. My original post shows a 2nd script without GROUP BY.
drew.allen
drew.allen
SSCertifiable
SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)SSCertifiable (6.3K reputation)

Group: General Forum Members
Points: 6320 Visits: 10871
JayWinter (7/31/2012)
I did remove the GROUP BY and and achieved the correct result. My original post shows a 2nd script without GROUP BY.


Your DISTINCT clause is hiding the problem. DISTINCT is processed after the GROUP BY, so any duplicates will be included in your totals for the GROUP BY, but will be excluded in your QA query.

DISTINCT is also superfluous in conjunction with a GROUP BY anyhow. The results of a simple GROUP BY statement are necessarily distinct. (That may not be the case if you have multiple grouping sets.)

Drew

J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
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