What are the benefits of using a CTE instead of this (which does work)? The 1 benefit that I do see is that calculating the sum once, instead of twice (once for the sales figure and once for ranking purposes) .
SELECT
AMFLIB . MBBFREP . CUSNO AS "Customer Number" , AMFLIB . MBBFREP . CUSNM AS "Customer Name" ,
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1091001 AND 1091231 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 12/31/09" ,
RANK() OVER (ORDER BY SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1091001 AND 1091231 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) DESC) AS "RANK 1",
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1081001 AND 1081231 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 12/31/08" ,
RANK() OVER (ORDER BY SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1081001 AND 1081231 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) DESC) AS "RANK 2",
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1071001 AND 1071231 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 12/31/07" ,
RANK() OVER (ORDER BY SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1071001 AND 1071231 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) DESC) AS "RANK 3",
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1100101 AND 1100331 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 03/31/10" ,
RANK() OVER (ORDER BY SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1100101 AND 1100331 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) DESC) AS "RANK 4",
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1090101 AND 1090331 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 03/31/09" ,
RANK() OVER (ORDER BY SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1090101 AND 1090331 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) DESC) AS "RANK 5",
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1080101 AND 1080331 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 03/31/08",
RANK() OVER (ORDER BY SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1080101 AND 1080331 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) DESC) AS "RANK 6"
FROM
AMFLIB . MBBFREP
-- Shipment Header
JOIN AMFLIB . MBDHREP
ON AMFLIB . MBBFREP . CUSNO = AMFLIB . MBDHREP . DHCANB
-- Shipment Details
JOIN AMFLIB . MBDDREP
-- ON Shipment #
ON AMFLIB . MBDHREP . DHZ969 = AMFLIB . MBDDREP . DDZ969
-- Invoice Header
JOIN AMFLIB . MBF9REP
-- ON Invoice #
ON AMFLIB . MBF9REP . FEGGNB = AMFLIB . MBDHREP . DHGGNB
WHERE
AMFLIB . MBDDREP . DDAXNB = 1 OR AMFLIB . MBDDREP . DDAAF4 = 1
GROUP BY
AMFLIB . MBBFREP . CUSNO ,
AMFLIB . MBBFREP . CUSNM
ORDER BY
"RANK 1" ASC
FETCH FIRST 50 ROWS ONLY;
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Birgitta Hauser
Sent: Wednesday, February 17, 2010 11:22 PM
To: 'Midrange Systems Technical Discussion'
Subject: AW: Ranking results
Hi,
have you tried to use a CTE for your SQL-Statement and specify RANK in the
final select?
With x as (YourSelect-Statement)
Select "Customer Name", "Rank 1", Rank() Over(Order By "Rank1) ....
From x
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training them
and keeping them!"
-----Ursprüngliche Nachricht-----
Von: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx] Im Auftrag von ibm
Gesendet: Wednesday, 17. February 2010 22:51
An: Midrange Systems Technical Discussion
Betreff: Ranking results
I am trying to figure out how to rank sales figures. The report would
return Q4 sales for 2009, 2009, 2007 with rankings varying for each year
depending on sales. I was trying to use Rank() but " An OLAP function
is not supported for this query.".
SELECT
AMFLIB . CUSMAS . CUSNO AS "Customer Number" , AMFLIB . CUSMAS .
CUSNM AS "Customer Name" ,
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1091001 AND
1091231 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 12/31/09" ,
0 AS "RANK 1",
--RANK() OVER (ORDER BY SUM ( CASE WHEN AMFLIB . MBF9REP .
FEGHNB BETWEEN 1091001 AND 1091231 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0
END ) ) AS "RANK 1",
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1081001 AND
1081231 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 12/31/08" ,
0 AS "RANK 2",
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1071001 AND
1071231 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 12/31/07" ,
0 AS "RANK 3",
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1100101 AND
1100331 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 03/31/10" ,
0 AS "RANK 4",
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1090101 AND
1090331 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 03/31/09" ,
0 AS "RANK 5",
SUM ( CASE WHEN AMFLIB . MBF9REP . FEGHNB BETWEEN 1080101 AND
1080331 THEN AMFLIB . MBDDREP . DDDUVA ELSE 0 END ) AS "QE 03/31/08",
0 AS "RANK 6"
FROM
AMFLIB . CUSMAS
-- Shipment Header
JOIN AMFLIB . MBDHREP
ON AMFLIB . CUSMAS . CUSNO = AMFLIB . MBDHREP .
DHCANB
-- Shipment Details
JOIN AMFLIB . MBDDREP
-- ON Shipment #
ON AMFLIB . MBDHREP . DHZ969 = AMFLIB . MBDDREP
. DDZ969
-- Invoice Header
JOIN AMFLIB . MBF9REP
-- ON Invoice #
ON AMFLIB . MBF9REP . FEGGNB = AMFLIB . MBDHREP
. DHGGNB
WHERE
AMFLIB . MBDDREP . DDAXNB = 1 OR AMFLIB . MBDDREP . DDAAF4 = 1
GROUP BY
AMFLIB . CUSMAS . CUSNO ,
AMFLIB . CUSMAS . CUSNM
ORDER BY
"QE 12/31/09" DESC
FETCH FIRST 50 ROWS ONLY;
As an Amazon Associate we earn from qualifying purchases.