1
0

query49.sql 3.7 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128
  1. select
  2. 'web' as channel
  3. ,web.item
  4. ,web.return_ratio
  5. ,web.return_rank
  6. ,web.currency_rank
  7. from (
  8. select
  9. item
  10. ,return_ratio
  11. ,currency_ratio
  12. ,rank() over (order by return_ratio) as return_rank
  13. ,rank() over (order by currency_ratio) as currency_rank
  14. from
  15. ( select ws.ws_item_sk as item
  16. ,(cast(sum(coalesce(wr.wr_return_quantity,0)) as decimal(15,4))/
  17. cast(sum(coalesce(ws.ws_quantity,0)) as decimal(15,4) )) as return_ratio
  18. ,(cast(sum(coalesce(wr.wr_return_amt,0)) as decimal(15,4))/
  19. cast(sum(coalesce(ws.ws_net_paid,0)) as decimal(15,4) )) as currency_ratio
  20. from
  21. web_sales ws left outer join web_returns wr
  22. on (ws.ws_order_number = wr.wr_order_number and
  23. ws.ws_item_sk = wr.wr_item_sk)
  24. ,date_dim
  25. where
  26. wr.wr_return_amt > 10000
  27. and ws.ws_net_profit > 1
  28. and ws.ws_net_paid > 0
  29. and ws.ws_quantity > 0
  30. and ws.ws_sold_date_sk = date_dim.d_date_sk
  31. and d_year = 2000
  32. and d_moy = 12
  33. group by ws.ws_item_sk
  34. ) in_web
  35. ) web
  36. where
  37. (
  38. web.return_rank <= 10
  39. or
  40. web.currency_rank <= 10
  41. )
  42. union all
  43. select
  44. 'catalog' as channel
  45. ,catalog.item
  46. ,catalog.return_ratio
  47. ,catalog.return_rank
  48. ,catalog.currency_rank
  49. from (
  50. select
  51. item
  52. ,return_ratio
  53. ,currency_ratio
  54. ,rank() over (order by return_ratio) as return_rank
  55. ,rank() over (order by currency_ratio) as currency_rank
  56. from
  57. ( select
  58. cs.cs_item_sk as item
  59. ,(cast(sum(coalesce(cr.cr_return_quantity,0)) as decimal(15,4))/
  60. cast(sum(coalesce(cs.cs_quantity,0)) as decimal(15,4) )) as return_ratio
  61. ,(cast(sum(coalesce(cr.cr_return_amount,0)) as decimal(15,4))/
  62. cast(sum(coalesce(cs.cs_net_paid,0)) as decimal(15,4) )) as currency_ratio
  63. from
  64. catalog_sales cs left outer join catalog_returns cr
  65. on (cs.cs_order_number = cr.cr_order_number and
  66. cs.cs_item_sk = cr.cr_item_sk)
  67. ,date_dim
  68. where
  69. cr.cr_return_amount > 10000
  70. and cs.cs_net_profit > 1
  71. and cs.cs_net_paid > 0
  72. and cs.cs_quantity > 0
  73. and cs_sold_date_sk = d_date_sk
  74. and d_year = 2000
  75. and d_moy = 12
  76. and cs_sold_date between '2000-12-01' and '2000-12-31'
  77. group by cs.cs_item_sk
  78. ) in_cat
  79. ) catalog
  80. where
  81. (
  82. catalog.return_rank <= 10
  83. or
  84. catalog.currency_rank <=10
  85. )
  86. union all
  87. select
  88. 'store' as channel
  89. ,store.item
  90. ,store.return_ratio
  91. ,store.return_rank
  92. ,store.currency_rank
  93. from (
  94. select
  95. item
  96. ,return_ratio
  97. ,currency_ratio
  98. ,rank() over (order by return_ratio) as return_rank
  99. ,rank() over (order by currency_ratio) as currency_rank
  100. from
  101. ( select sts.ss_item_sk as item
  102. ,(cast(sum(coalesce(sr.sr_return_quantity,0)) as decimal(15,4))/cast(sum(coalesce(sts.ss_quantity,0)) as decimal(15,4) )) as return_ratio
  103. ,(cast(sum(coalesce(sr.sr_return_amt,0)) as decimal(15,4))/cast(sum(coalesce(sts.ss_net_paid,0)) as decimal(15,4) )) as currency_ratio
  104. from
  105. store_sales sts left outer join store_returns sr
  106. on (sts.ss_ticket_number = sr.sr_ticket_number and sts.ss_item_sk = sr.sr_item_sk)
  107. ,date_dim
  108. where
  109. sr.sr_return_amt > 10000
  110. and sts.ss_net_profit > 1
  111. and sts.ss_net_paid > 0
  112. and sts.ss_quantity > 0
  113. and ss_sold_date_sk = d_date_sk
  114. and d_year = 2000
  115. and d_moy = 12
  116. group by sts.ss_item_sk
  117. ) in_store
  118. ) store
  119. where (
  120. store.return_rank <= 10
  121. or
  122. store.currency_rank <= 10
  123. )
  124. order by 1,4,5
  125. limit 100;