query66.sql 7.6 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222
  1. -- start query 1 in stream 0 using template query66.tpl and seed 2042478054
  2. select
  3. w_warehouse_name
  4. ,w_warehouse_sq_ft
  5. ,w_city
  6. ,w_county
  7. ,w_state
  8. ,w_country
  9. ,ship_carriers
  10. ,year
  11. ,sum(jan_sales) as jan_sales
  12. ,sum(feb_sales) as feb_sales
  13. ,sum(mar_sales) as mar_sales
  14. ,sum(apr_sales) as apr_sales
  15. ,sum(may_sales) as may_sales
  16. ,sum(jun_sales) as jun_sales
  17. ,sum(jul_sales) as jul_sales
  18. ,sum(aug_sales) as aug_sales
  19. ,sum(sep_sales) as sep_sales
  20. ,sum(oct_sales) as oct_sales
  21. ,sum(nov_sales) as nov_sales
  22. ,sum(dec_sales) as dec_sales
  23. ,sum(jan_sales/w_warehouse_sq_ft) as jan_sales_per_sq_foot
  24. ,sum(feb_sales/w_warehouse_sq_ft) as feb_sales_per_sq_foot
  25. ,sum(mar_sales/w_warehouse_sq_ft) as mar_sales_per_sq_foot
  26. ,sum(apr_sales/w_warehouse_sq_ft) as apr_sales_per_sq_foot
  27. ,sum(may_sales/w_warehouse_sq_ft) as may_sales_per_sq_foot
  28. ,sum(jun_sales/w_warehouse_sq_ft) as jun_sales_per_sq_foot
  29. ,sum(jul_sales/w_warehouse_sq_ft) as jul_sales_per_sq_foot
  30. ,sum(aug_sales/w_warehouse_sq_ft) as aug_sales_per_sq_foot
  31. ,sum(sep_sales/w_warehouse_sq_ft) as sep_sales_per_sq_foot
  32. ,sum(oct_sales/w_warehouse_sq_ft) as oct_sales_per_sq_foot
  33. ,sum(nov_sales/w_warehouse_sq_ft) as nov_sales_per_sq_foot
  34. ,sum(dec_sales/w_warehouse_sq_ft) as dec_sales_per_sq_foot
  35. ,sum(jan_net) as jan_net
  36. ,sum(feb_net) as feb_net
  37. ,sum(mar_net) as mar_net
  38. ,sum(apr_net) as apr_net
  39. ,sum(may_net) as may_net
  40. ,sum(jun_net) as jun_net
  41. ,sum(jul_net) as jul_net
  42. ,sum(aug_net) as aug_net
  43. ,sum(sep_net) as sep_net
  44. ,sum(oct_net) as oct_net
  45. ,sum(nov_net) as nov_net
  46. ,sum(dec_net) as dec_net
  47. from (
  48. (select
  49. w_warehouse_name
  50. ,w_warehouse_sq_ft
  51. ,w_city
  52. ,w_county
  53. ,w_state
  54. ,w_country
  55. ,'DIAMOND' || ',' || 'AIRBORNE' as ship_carriers
  56. ,d_year as year
  57. ,sum(case when d_moy = 1
  58. then ws_sales_price* ws_quantity else 0 end) as jan_sales
  59. ,sum(case when d_moy = 2
  60. then ws_sales_price* ws_quantity else 0 end) as feb_sales
  61. ,sum(case when d_moy = 3
  62. then ws_sales_price* ws_quantity else 0 end) as mar_sales
  63. ,sum(case when d_moy = 4
  64. then ws_sales_price* ws_quantity else 0 end) as apr_sales
  65. ,sum(case when d_moy = 5
  66. then ws_sales_price* ws_quantity else 0 end) as may_sales
  67. ,sum(case when d_moy = 6
  68. then ws_sales_price* ws_quantity else 0 end) as jun_sales
  69. ,sum(case when d_moy = 7
  70. then ws_sales_price* ws_quantity else 0 end) as jul_sales
  71. ,sum(case when d_moy = 8
  72. then ws_sales_price* ws_quantity else 0 end) as aug_sales
  73. ,sum(case when d_moy = 9
  74. then ws_sales_price* ws_quantity else 0 end) as sep_sales
  75. ,sum(case when d_moy = 10
  76. then ws_sales_price* ws_quantity else 0 end) as oct_sales
  77. ,sum(case when d_moy = 11
  78. then ws_sales_price* ws_quantity else 0 end) as nov_sales
  79. ,sum(case when d_moy = 12
  80. then ws_sales_price* ws_quantity else 0 end) as dec_sales
  81. ,sum(case when d_moy = 1
  82. then ws_net_paid_inc_tax * ws_quantity else 0 end) as jan_net
  83. ,sum(case when d_moy = 2
  84. then ws_net_paid_inc_tax * ws_quantity else 0 end) as feb_net
  85. ,sum(case when d_moy = 3
  86. then ws_net_paid_inc_tax * ws_quantity else 0 end) as mar_net
  87. ,sum(case when d_moy = 4
  88. then ws_net_paid_inc_tax * ws_quantity else 0 end) as apr_net
  89. ,sum(case when d_moy = 5
  90. then ws_net_paid_inc_tax * ws_quantity else 0 end) as may_net
  91. ,sum(case when d_moy = 6
  92. then ws_net_paid_inc_tax * ws_quantity else 0 end) as jun_net
  93. ,sum(case when d_moy = 7
  94. then ws_net_paid_inc_tax * ws_quantity else 0 end) as jul_net
  95. ,sum(case when d_moy = 8
  96. then ws_net_paid_inc_tax * ws_quantity else 0 end) as aug_net
  97. ,sum(case when d_moy = 9
  98. then ws_net_paid_inc_tax * ws_quantity else 0 end) as sep_net
  99. ,sum(case when d_moy = 10
  100. then ws_net_paid_inc_tax * ws_quantity else 0 end) as oct_net
  101. ,sum(case when d_moy = 11
  102. then ws_net_paid_inc_tax * ws_quantity else 0 end) as nov_net
  103. ,sum(case when d_moy = 12
  104. then ws_net_paid_inc_tax * ws_quantity else 0 end) as dec_net
  105. from
  106. web_sales
  107. ,warehouse
  108. ,date_dim
  109. ,time_dim
  110. ,ship_mode
  111. where
  112. ws_warehouse_sk = w_warehouse_sk
  113. and ws_sold_date_sk = d_date_sk
  114. and ws_sold_time_sk = t_time_sk
  115. and ws_ship_mode_sk = sm_ship_mode_sk
  116. and d_year = 2002
  117. and t_time between 49530 and 49530+28800
  118. and sm_carrier in ('DIAMOND','AIRBORNE')
  119. group by
  120. w_warehouse_name
  121. ,w_warehouse_sq_ft
  122. ,w_city
  123. ,w_county
  124. ,w_state
  125. ,w_country
  126. ,d_year
  127. )
  128. union all
  129. (select
  130. w_warehouse_name
  131. ,w_warehouse_sq_ft
  132. ,w_city
  133. ,w_county
  134. ,w_state
  135. ,w_country
  136. ,'DIAMOND' || ',' || 'AIRBORNE' as ship_carriers
  137. ,d_year as year
  138. ,sum(case when d_moy = 1
  139. then cs_ext_sales_price* cs_quantity else 0 end) as jan_sales
  140. ,sum(case when d_moy = 2
  141. then cs_ext_sales_price* cs_quantity else 0 end) as feb_sales
  142. ,sum(case when d_moy = 3
  143. then cs_ext_sales_price* cs_quantity else 0 end) as mar_sales
  144. ,sum(case when d_moy = 4
  145. then cs_ext_sales_price* cs_quantity else 0 end) as apr_sales
  146. ,sum(case when d_moy = 5
  147. then cs_ext_sales_price* cs_quantity else 0 end) as may_sales
  148. ,sum(case when d_moy = 6
  149. then cs_ext_sales_price* cs_quantity else 0 end) as jun_sales
  150. ,sum(case when d_moy = 7
  151. then cs_ext_sales_price* cs_quantity else 0 end) as jul_sales
  152. ,sum(case when d_moy = 8
  153. then cs_ext_sales_price* cs_quantity else 0 end) as aug_sales
  154. ,sum(case when d_moy = 9
  155. then cs_ext_sales_price* cs_quantity else 0 end) as sep_sales
  156. ,sum(case when d_moy = 10
  157. then cs_ext_sales_price* cs_quantity else 0 end) as oct_sales
  158. ,sum(case when d_moy = 11
  159. then cs_ext_sales_price* cs_quantity else 0 end) as nov_sales
  160. ,sum(case when d_moy = 12
  161. then cs_ext_sales_price* cs_quantity else 0 end) as dec_sales
  162. ,sum(case when d_moy = 1
  163. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as jan_net
  164. ,sum(case when d_moy = 2
  165. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as feb_net
  166. ,sum(case when d_moy = 3
  167. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as mar_net
  168. ,sum(case when d_moy = 4
  169. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as apr_net
  170. ,sum(case when d_moy = 5
  171. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as may_net
  172. ,sum(case when d_moy = 6
  173. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as jun_net
  174. ,sum(case when d_moy = 7
  175. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as jul_net
  176. ,sum(case when d_moy = 8
  177. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as aug_net
  178. ,sum(case when d_moy = 9
  179. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as sep_net
  180. ,sum(case when d_moy = 10
  181. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as oct_net
  182. ,sum(case when d_moy = 11
  183. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as nov_net
  184. ,sum(case when d_moy = 12
  185. then cs_net_paid_inc_ship_tax * cs_quantity else 0 end) as dec_net
  186. from
  187. catalog_sales
  188. ,warehouse
  189. ,date_dim
  190. ,time_dim
  191. ,ship_mode
  192. where
  193. cs_warehouse_sk = w_warehouse_sk
  194. and cs_sold_date_sk = d_date_sk
  195. and cs_sold_time_sk = t_time_sk
  196. and cs_ship_mode_sk = sm_ship_mode_sk
  197. and d_year = 2002
  198. and t_time between 49530 AND 49530+28800
  199. and sm_carrier in ('DIAMOND','AIRBORNE')
  200. group by
  201. w_warehouse_name
  202. ,w_warehouse_sq_ft
  203. ,w_city
  204. ,w_county
  205. ,w_state
  206. ,w_country
  207. ,d_year
  208. )
  209. ) x
  210. group by
  211. w_warehouse_name
  212. ,w_warehouse_sq_ft
  213. ,w_city
  214. ,w_county
  215. ,w_state
  216. ,w_country
  217. ,ship_carriers
  218. ,year
  219. order by w_warehouse_name
  220. limit 100;
  221. -- end query 1 in stream 0 using template query66.tpl