forked from agirish/tpcds
-
Notifications
You must be signed in to change notification settings - Fork 0
/
query49.sql
133 lines (133 loc) · 5.69 KB
/
query49.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
-- start query 49 in stream 0 using template query49.tpl
SELECT 'web' AS channel,
web.item,
web.return_ratio,
web.return_rank,
web.currency_rank
FROM (SELECT item,
return_ratio,
currency_ratio,
Rank()
OVER (
ORDER BY return_ratio) AS return_rank,
Rank()
OVER (
ORDER BY currency_ratio) AS currency_rank
FROM (SELECT ws.ws_item_sk AS
item,
( Cast(Sum(COALESCE(wr.wr_return_quantity, 0)) AS DEC(15,
4)) /
Cast(
Sum(COALESCE(ws.ws_quantity, 0)) AS DEC(15, 4)) ) AS
return_ratio,
( Cast(Sum(COALESCE(wr.wr_return_amt, 0)) AS DEC(15, 4))
/ Cast(
Sum(
COALESCE(ws.ws_net_paid, 0)) AS DEC(15,
4)) ) AS
currency_ratio
FROM web_sales ws
LEFT OUTER JOIN web_returns wr
ON ( ws.ws_order_number = wr.wr_order_number
AND ws.ws_item_sk = wr.wr_item_sk ),
date_dim
WHERE wr.wr_return_amt > 10000
AND ws.ws_net_profit > 1
AND ws.ws_net_paid > 0
AND ws.ws_quantity > 0
AND ws_sold_date_sk = d_date_sk
AND d_year = 1999
AND d_moy = 12
GROUP BY ws.ws_item_sk) in_web) web
WHERE ( web.return_rank <= 10
OR web.currency_rank <= 10 )
UNION
SELECT 'catalog' AS channel,
catalog.item,
catalog.return_ratio,
catalog.return_rank,
catalog.currency_rank
FROM (SELECT item,
return_ratio,
currency_ratio,
Rank()
OVER (
ORDER BY return_ratio) AS return_rank,
Rank()
OVER (
ORDER BY currency_ratio) AS currency_rank
FROM (SELECT cs.cs_item_sk AS
item,
( Cast(Sum(COALESCE(cr.cr_return_quantity, 0)) AS DEC(15,
4)) /
Cast(
Sum(COALESCE(cs.cs_quantity, 0)) AS DEC(15, 4)) ) AS
return_ratio,
( Cast(Sum(COALESCE(cr.cr_return_amount, 0)) AS DEC(15, 4
)) /
Cast(Sum(
COALESCE(cs.cs_net_paid, 0)) AS DEC(
15, 4)) ) AS
currency_ratio
FROM catalog_sales cs
LEFT OUTER JOIN catalog_returns cr
ON ( cs.cs_order_number = cr.cr_order_number
AND cs.cs_item_sk = cr.cr_item_sk ),
date_dim
WHERE cr.cr_return_amount > 10000
AND cs.cs_net_profit > 1
AND cs.cs_net_paid > 0
AND cs.cs_quantity > 0
AND cs_sold_date_sk = d_date_sk
AND d_year = 1999
AND d_moy = 12
GROUP BY cs.cs_item_sk) in_cat) catalog
WHERE ( catalog.return_rank <= 10
OR catalog.currency_rank <= 10 )
UNION
SELECT 'store' AS channel,
store.item,
store.return_ratio,
store.return_rank,
store.currency_rank
FROM (SELECT item,
return_ratio,
currency_ratio,
Rank()
OVER (
ORDER BY return_ratio) AS return_rank,
Rank()
OVER (
ORDER BY currency_ratio) AS currency_rank
FROM (SELECT sts.ss_item_sk AS
item,
( Cast(Sum(COALESCE(sr.sr_return_quantity, 0)) AS DEC(15,
4)) /
Cast(
Sum(COALESCE(sts.ss_quantity, 0)) AS DEC(15, 4)) ) AS
return_ratio,
( Cast(Sum(COALESCE(sr.sr_return_amt, 0)) AS DEC(15, 4))
/ Cast(
Sum(
COALESCE(sts.ss_net_paid, 0)) AS DEC(15, 4)) ) AS
currency_ratio
FROM store_sales sts
LEFT OUTER JOIN store_returns sr
ON ( sts.ss_ticket_number =
sr.sr_ticket_number
AND sts.ss_item_sk = sr.sr_item_sk ),
date_dim
WHERE sr.sr_return_amt > 10000
AND sts.ss_net_profit > 1
AND sts.ss_net_paid > 0
AND sts.ss_quantity > 0
AND ss_sold_date_sk = d_date_sk
AND d_year = 1999
AND d_moy = 12
GROUP BY sts.ss_item_sk) in_store) store
WHERE ( store.return_rank <= 10
OR store.currency_rank <= 10 )
ORDER BY 1,
4,
5
LIMIT 100;