query5.sql 3.9 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128
  1. -- start query 1 in stream 0 using template query5.tpl and seed 1819994127
  2. with ssr as
  3. (select s_store_id,
  4. sum(sales_price) as sales,
  5. sum(profit) as profit,
  6. sum(return_amt) as returns,
  7. sum(net_loss) as profit_loss
  8. from
  9. ( select ss_store_sk as store_sk,
  10. ss_sold_date_sk as date_sk,
  11. ss_ext_sales_price as sales_price,
  12. ss_net_profit as profit,
  13. cast(0 as decimal(7,2)) as return_amt,
  14. cast(0 as decimal(7,2)) as net_loss
  15. from store_sales
  16. union all
  17. select sr_store_sk as store_sk,
  18. sr_returned_date_sk as date_sk,
  19. cast(0 as decimal(7,2)) as sales_price,
  20. cast(0 as decimal(7,2)) as profit,
  21. sr_return_amt as return_amt,
  22. sr_net_loss as net_loss
  23. from store_returns
  24. ) salesreturns,
  25. date_dim,
  26. store
  27. where date_sk = d_date_sk
  28. and d_date between cast('2000-08-19' as date)
  29. and (cast('2000-08-19' as date) + 14 days)
  30. and store_sk = s_store_sk
  31. group by s_store_id)
  32. ,
  33. csr as
  34. (select cp_catalog_page_id,
  35. sum(sales_price) as sales,
  36. sum(profit) as profit,
  37. sum(return_amt) as returns,
  38. sum(net_loss) as profit_loss
  39. from
  40. ( select cs_catalog_page_sk as page_sk,
  41. cs_sold_date_sk as date_sk,
  42. cs_ext_sales_price as sales_price,
  43. cs_net_profit as profit,
  44. cast(0 as decimal(7,2)) as return_amt,
  45. cast(0 as decimal(7,2)) as net_loss
  46. from catalog_sales
  47. union all
  48. select cr_catalog_page_sk as page_sk,
  49. cr_returned_date_sk as date_sk,
  50. cast(0 as decimal(7,2)) as sales_price,
  51. cast(0 as decimal(7,2)) as profit,
  52. cr_return_amount as return_amt,
  53. cr_net_loss as net_loss
  54. from catalog_returns
  55. ) salesreturns,
  56. date_dim,
  57. catalog_page
  58. where date_sk = d_date_sk
  59. and d_date between cast('2000-08-19' as date)
  60. and (cast('2000-08-19' as date) + 14 days)
  61. and page_sk = cp_catalog_page_sk
  62. group by cp_catalog_page_id)
  63. ,
  64. wsr as
  65. (select web_site_id,
  66. sum(sales_price) as sales,
  67. sum(profit) as profit,
  68. sum(return_amt) as returns,
  69. sum(net_loss) as profit_loss
  70. from
  71. ( select ws_web_site_sk as wsr_web_site_sk,
  72. ws_sold_date_sk as date_sk,
  73. ws_ext_sales_price as sales_price,
  74. ws_net_profit as profit,
  75. cast(0 as decimal(7,2)) as return_amt,
  76. cast(0 as decimal(7,2)) as net_loss
  77. from web_sales
  78. union all
  79. select ws_web_site_sk as wsr_web_site_sk,
  80. wr_returned_date_sk as date_sk,
  81. cast(0 as decimal(7,2)) as sales_price,
  82. cast(0 as decimal(7,2)) as profit,
  83. wr_return_amt as return_amt,
  84. wr_net_loss as net_loss
  85. from web_returns left outer join web_sales on
  86. ( wr_item_sk = ws_item_sk
  87. and wr_order_number = ws_order_number)
  88. ) salesreturns,
  89. date_dim,
  90. web_site
  91. where date_sk = d_date_sk
  92. and d_date between cast('2000-08-19' as date)
  93. and (cast('2000-08-19' as date) + 14 days)
  94. and wsr_web_site_sk = web_site_sk
  95. group by web_site_id)
  96. select channel
  97. , id
  98. , sum(sales) as sales
  99. , sum(returns) as returns
  100. , sum(profit) as profit
  101. from
  102. (select 'store channel' as channel
  103. , 'store' || s_store_id as id
  104. , sales
  105. , returns
  106. , (profit - profit_loss) as profit
  107. from ssr
  108. union all
  109. select 'catalog channel' as channel
  110. , 'catalog_page' || cp_catalog_page_id as id
  111. , sales
  112. , returns
  113. , (profit - profit_loss) as profit
  114. from csr
  115. union all
  116. select 'web channel' as channel
  117. , 'web_site' || web_site_id as id
  118. , sales
  119. , returns
  120. , (profit - profit_loss) as profit
  121. from wsr
  122. ) x
  123. group by rollup (channel, id)
  124. order by channel
  125. ,id
  126. limit 100;
  127. -- end query 1 in stream 0 using template query5.tpl