Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Aggregate/Group Query with CASE


Aggregate/Group Query with CASE

Author
Message
marcossuriel
marcossuriel
Grasshopper
Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)

Group: General Forum Members
Points: 20 Visits: 86
Hello Everyone,

Thank you for reading my post. I think I'm half way from where I need to be with this query below. My end goal is to be able to list the Top (N) customers based on sales totals. So far I can get a list of all customers with their information for each order, pretty straight forward. This is what my query currently produce (I shortened the field names from the query, just to make it easier):

CustNo CustName, Addr1, Addr2 City State Zip SalesTotal
123 ABC .... .... ... .... ... 100
123 ABC .... .... ... .... ... 150
456 DEF .... .... ... .... ... 200
456 DEF .... .... ... .... ... 250
789 GHI .... .... ... .... ... 300
789 GHI .... .... ... .... ... 350

However, this is what I want to produce: grouping the results by customer and aggregate the sales amounts, sorted by highest to lowest like this:


CustNo CustName, Addr1, Addr2 City State Zip SalesTotal
789 GHI .... .... ... .... ... 650
456 DEF .... .... ... .... ... 450
123 ABC .... .... ... .... ... 250

I havne't been able to figure this out to save my life, but I'm sure it's possible. I look forward to hearing back from you, thank you soooo much.

My query below:


DECLARE @StartYear CHAR(4);
DECLARE @EndYear CHAR(4);
DECLARE @StartMonth SMALLINT;
DECLARE @EndMonth SMALLINT;
DECLARE @TopN SMALLINT;

SET @StartYear = 2014
SET @EndYear = 2014
SET @StartMonth = 1
SET @EndMonth = 3
SET @TopN = 10

SELECT OrdHist.CUSTOMER AS [Customer No.], Cust.NAMECUST AS [Customer Name], Cust.TEXTSTRE1 AS [Address1], Cust.TEXTSTRE2 AS [Address2],
Cust.NAMECITY AS City, Cust.CODESTTE AS [State], Cust.CODEPSTL AS Zip,
CASE
WHEN OrdHist.TRANTYPE=1 THEN OrdHist.FAMTSALES
WHEN OrdHist.TRANTYPE=2 AND OrdHist.FRETSALES = 0 THEN OrdHist.FAMTSALES
ELSE OrdHist.FRETSALES * -1
END AS [Sale / Return Amount]
FROM OESHDT OrdHist INNER JOIN ARCUS Cust ON OrdHist.CUSTOMER = Cust.IDCUST
WHERE OrdHist.YR BETWEEN @StartYear AND @EndYear AND OrdHist.PERIOD BETWEEN @StartMonth AND @EndMonth
ORDER BY OrdHist.CUSTOMER ASC
Lynn Pettis
Lynn Pettis
SSC-Insane
SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)

Group: General Forum Members
Points: 24200 Visits: 37964
marcossuriel (3/22/2014)
Hello Everyone,

Thank you for reading my post. I think I'm half way from where I need to be with this query below. My end goal is to be able to list the Top (N) customers based on sales totals. So far I can get a list of all customers with their information for each order, pretty straight forward. This is what my query currently produce (I shortened the field names from the query, just to make it easier):

CustNo CustName, Addr1, Addr2 City State Zip SalesTotal
123 ABC .... .... ... .... ... 100
123 ABC .... .... ... .... ... 150
456 DEF .... .... ... .... ... 200
456 DEF .... .... ... .... ... 250
789 GHI .... .... ... .... ... 300
789 GHI .... .... ... .... ... 350

However, this is what I want to produce: grouping the results by customer and aggregate the sales amounts, sorted by highest to lowest like this:


CustNo CustName, Addr1, Addr2 City State Zip SalesTotal
789 GHI .... .... ... .... ... 650
456 DEF .... .... ... .... ... 450
123 ABC .... .... ... .... ... 250

I havne't been able to figure this out to save my life, but I'm sure it's possible. I look forward to hearing back from you, thank you soooo much.

My query below:


DECLARE @StartYear CHAR(4);
DECLARE @EndYear CHAR(4);
DECLARE @StartMonth SMALLINT;
DECLARE @EndMonth SMALLINT;
DECLARE @TopN SMALLINT;

SET @StartYear = 2014
SET @EndYear = 2014
SET @StartMonth = 1
SET @EndMonth = 3
SET @TopN = 10

SELECT OrdHist.CUSTOMER AS [Customer No.], Cust.NAMECUST AS [Customer Name], Cust.TEXTSTRE1 AS [Address1], Cust.TEXTSTRE2 AS [Address2],
Cust.NAMECITY AS City, Cust.CODESTTE AS [State], Cust.CODEPSTL AS Zip,
CASE
WHEN OrdHist.TRANTYPE=1 THEN OrdHist.FAMTSALES
WHEN OrdHist.TRANTYPE=2 AND OrdHist.FRETSALES = 0 THEN OrdHist.FAMTSALES
ELSE OrdHist.FRETSALES * -1
END AS [Sale / Return Amount]
FROM OESHDT OrdHist INNER JOIN ARCUS Cust ON OrdHist.CUSTOMER = Cust.IDCUST
WHERE OrdHist.YR BETWEEN @StartYear AND @EndYear AND OrdHist.PERIOD BETWEEN @StartMonth AND @EndMonth
ORDER BY OrdHist.CUSTOMER ASC




Since you didn't provide the DDL or sample data for the tables involved in this query, the following is a shot in the dark to meet your requirements.



SELECT OrdHist.CUSTOMER AS [Customer No.]
,Cust.NAMECUST AS [Customer Name]
,Cust.TEXTSTRE1 AS [Address1]
,Cust.TEXTSTRE2 AS [Address2]
,Cust.NAMECITY AS City
,Cust.CODESTTE AS [State]
,Cust.CODEPSTL AS Zip
,SUM(CASE
WHEN OrdHist.TRANTYPE = 1
THEN OrdHist.FAMTSALES
WHEN OrdHist.TRANTYPE = 2
AND OrdHist.FRETSALES = 0
THEN OrdHist.FAMTSALES
ELSE OrdHist.FRETSALES * - 1
END) AS [Sale / Return Amount]
FROM OESHDT OrdHist
INNER JOIN ARCUS Cust ON OrdHist.CUSTOMER = Cust.IDCUST
WHERE OrdHist.YR BETWEEN @StartYear
AND @EndYear
AND OrdHist.PERIOD BETWEEN @StartMonth
AND @EndMonth
GROUP BY
OrdHist.CUSTOMER
,Cust.NAMECUST
,Cust.TEXTSTRE1
,Cust.TEXTSTRE2
,Cust.NAMECITY
,Cust.CODESTTE
,Cust.CODEPSTL
ORDER BY
[Sale / Return Amount] DESC;




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
jpk 91966
jpk 91966
SSC Rookie
SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)

Group: General Forum Members
Points: 42 Visits: 82
Why dont you just do it as a sub query?

DECLARE @StartYear CHAR(4);
DECLARE @EndYear CHAR(4);
DECLARE @StartMonth SMALLINT;
DECLARE @EndMonth SMALLINT;
DECLARE @TopN SMALLINT;

SET @StartYear = 2014
SET @EndYear = 2014
SET @StartMonth = 1
SET @EndMonth = 3
SET @TopN = 10

select [Customer No.], [Customer Name], [Address1], TEXTSTRE2, [Address2], City, [State], Zip, sum([Sale / Return Amount]) [Sale / Return Amount Total]
from(
SELECT OrdHist.CUSTOMER AS [Customer No.], Cust.NAMECUST AS [Customer Name], Cust.TEXTSTRE1 AS [Address1], Cust.TEXTSTRE2 AS [Address2],
Cust.NAMECITY AS City, Cust.CODESTTE AS [State], Cust.CODEPSTL AS Zip,
CASE
WHEN OrdHist.TRANTYPE=1 THEN OrdHist.FAMTSALES
WHEN OrdHist.TRANTYPE=2 AND OrdHist.FRETSALES = 0 THEN OrdHist.FAMTSALES
ELSE OrdHist.FRETSALES * -1
END AS [Sale / Return Amount]
FROM OESHDT OrdHist INNER JOIN ARCUS Cust ON OrdHist.CUSTOMER = Cust.IDCUST
WHERE OrdHist.YR BETWEEN @StartYear AND @EndYear AND OrdHist.PERIOD BETWEEN @StartMonth AND @EndMonth
--ORDER BY OrdHist.CUSTOMER ASC
) as d
group by [Customer No.], [Customer Name], [Address1], TEXTSTRE2, [Address2], City, [State], Zip
order by [Customer No.]

Thanks,
John
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