1
0

query14.sql 7.3 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210
  1. -- start query 1 in stream 0 using template query14.tpl and seed 1819994127
  2. with cross_items as
  3. (select i_item_sk ss_item_sk
  4. from item,
  5. (select iss.i_brand_id brand_id
  6. ,iss.i_class_id class_id
  7. ,iss.i_category_id category_id
  8. from store_sales
  9. ,item iss
  10. ,date_dim d1
  11. where ss_item_sk = iss.i_item_sk
  12. and ss_sold_date_sk = d1.d_date_sk
  13. and d1.d_year between 2000 AND 2000 + 2
  14. intersect
  15. select ics.i_brand_id
  16. ,ics.i_class_id
  17. ,ics.i_category_id
  18. from catalog_sales
  19. ,item ics
  20. ,date_dim d2
  21. where cs_item_sk = ics.i_item_sk
  22. and cs_sold_date_sk = d2.d_date_sk
  23. and d2.d_year between 2000 AND 2000 + 2
  24. intersect
  25. select iws.i_brand_id
  26. ,iws.i_class_id
  27. ,iws.i_category_id
  28. from web_sales
  29. ,item iws
  30. ,date_dim d3
  31. where ws_item_sk = iws.i_item_sk
  32. and ws_sold_date_sk = d3.d_date_sk
  33. and d3.d_year between 2000 AND 2000 + 2) x
  34. where i_brand_id = brand_id
  35. and i_class_id = class_id
  36. and i_category_id = category_id
  37. ),
  38. avg_sales as
  39. (select avg(quantity*list_price) average_sales
  40. from (select ss_quantity quantity
  41. ,ss_list_price list_price
  42. from store_sales
  43. ,date_dim
  44. where ss_sold_date_sk = d_date_sk
  45. and d_year between 2000 and 2000 + 2
  46. union all
  47. select cs_quantity quantity
  48. ,cs_list_price list_price
  49. from catalog_sales
  50. ,date_dim
  51. where cs_sold_date_sk = d_date_sk
  52. and d_year between 2000 and 2000 + 2
  53. union all
  54. select ws_quantity quantity
  55. ,ws_list_price list_price
  56. from web_sales
  57. ,date_dim
  58. where ws_sold_date_sk = d_date_sk
  59. and d_year between 2000 and 2000 + 2) x)
  60. select channel, i_brand_id,i_class_id,i_category_id,sum(sales), sum(number_sales)
  61. from(
  62. select 'store' channel, i_brand_id,i_class_id
  63. ,i_category_id,sum(ss_quantity*ss_list_price) sales
  64. , count(*) number_sales
  65. from store_sales
  66. ,item
  67. ,date_dim
  68. where ss_item_sk in (select ss_item_sk from cross_items)
  69. and ss_item_sk = i_item_sk
  70. and ss_sold_date_sk = d_date_sk
  71. and d_year = 2000+2
  72. and d_moy = 11
  73. group by i_brand_id,i_class_id,i_category_id
  74. having sum(ss_quantity*ss_list_price) > (select average_sales from avg_sales)
  75. union all
  76. select 'catalog' channel, i_brand_id,i_class_id,i_category_id, sum(cs_quantity*cs_list_price) sales, count(*) number_sales
  77. from catalog_sales
  78. ,item
  79. ,date_dim
  80. where cs_item_sk in (select ss_item_sk from cross_items)
  81. and cs_item_sk = i_item_sk
  82. and cs_sold_date_sk = d_date_sk
  83. and d_year = 2000+2
  84. and d_moy = 11
  85. group by i_brand_id,i_class_id,i_category_id
  86. having sum(cs_quantity*cs_list_price) > (select average_sales from avg_sales)
  87. union all
  88. select 'web' channel, i_brand_id,i_class_id,i_category_id, sum(ws_quantity*ws_list_price) sales , count(*) number_sales
  89. from web_sales
  90. ,item
  91. ,date_dim
  92. where ws_item_sk in (select ss_item_sk from cross_items)
  93. and ws_item_sk = i_item_sk
  94. and ws_sold_date_sk = d_date_sk
  95. and d_year = 2000+2
  96. and d_moy = 11
  97. group by i_brand_id,i_class_id,i_category_id
  98. having sum(ws_quantity*ws_list_price) > (select average_sales from avg_sales)
  99. ) y
  100. group by rollup (channel, i_brand_id,i_class_id,i_category_id)
  101. order by channel,i_brand_id,i_class_id,i_category_id
  102. limit 100;
  103. with cross_items as
  104. (select i_item_sk ss_item_sk
  105. from item,
  106. (select iss.i_brand_id brand_id
  107. ,iss.i_class_id class_id
  108. ,iss.i_category_id category_id
  109. from store_sales
  110. ,item iss
  111. ,date_dim d1
  112. where ss_item_sk = iss.i_item_sk
  113. and ss_sold_date_sk = d1.d_date_sk
  114. and d1.d_year between 2000 AND 2000 + 2
  115. intersect
  116. select ics.i_brand_id
  117. ,ics.i_class_id
  118. ,ics.i_category_id
  119. from catalog_sales
  120. ,item ics
  121. ,date_dim d2
  122. where cs_item_sk = ics.i_item_sk
  123. and cs_sold_date_sk = d2.d_date_sk
  124. and d2.d_year between 2000 AND 2000 + 2
  125. intersect
  126. select iws.i_brand_id
  127. ,iws.i_class_id
  128. ,iws.i_category_id
  129. from web_sales
  130. ,item iws
  131. ,date_dim d3
  132. where ws_item_sk = iws.i_item_sk
  133. and ws_sold_date_sk = d3.d_date_sk
  134. and d3.d_year between 2000 AND 2000 + 2) x
  135. where i_brand_id = brand_id
  136. and i_class_id = class_id
  137. and i_category_id = category_id
  138. ),
  139. avg_sales as
  140. (select avg(quantity*list_price) average_sales
  141. from (select ss_quantity quantity
  142. ,ss_list_price list_price
  143. from store_sales
  144. ,date_dim
  145. where ss_sold_date_sk = d_date_sk
  146. and d_year between 2000 and 2000 + 2
  147. union all
  148. select cs_quantity quantity
  149. ,cs_list_price list_price
  150. from catalog_sales
  151. ,date_dim
  152. where cs_sold_date_sk = d_date_sk
  153. and d_year between 2000 and 2000 + 2
  154. union all
  155. select ws_quantity quantity
  156. ,ws_list_price list_price
  157. from web_sales
  158. ,date_dim
  159. where ws_sold_date_sk = d_date_sk
  160. and d_year between 2000 and 2000 + 2) x)
  161. select this_year.channel ty_channel
  162. ,this_year.i_brand_id ty_brand
  163. ,this_year.i_class_id ty_class
  164. ,this_year.i_category_id ty_category
  165. ,this_year.sales ty_sales
  166. ,this_year.number_sales ty_number_sales
  167. ,last_year.channel ly_channel
  168. ,last_year.i_brand_id ly_brand
  169. ,last_year.i_class_id ly_class
  170. ,last_year.i_category_id ly_category
  171. ,last_year.sales ly_sales
  172. ,last_year.number_sales ly_number_sales
  173. from
  174. (select 'store' channel, i_brand_id,i_class_id,i_category_id
  175. ,sum(ss_quantity*ss_list_price) sales, count(*) number_sales
  176. from store_sales
  177. ,item
  178. ,date_dim
  179. where ss_item_sk in (select ss_item_sk from cross_items)
  180. and ss_item_sk = i_item_sk
  181. and ss_sold_date_sk = d_date_sk
  182. and d_week_seq = (select d_week_seq
  183. from date_dim
  184. where d_year = 2000 + 1
  185. and d_moy = 12
  186. and d_dom = 15)
  187. group by i_brand_id,i_class_id,i_category_id
  188. having sum(ss_quantity*ss_list_price) > (select average_sales from avg_sales)) this_year,
  189. (select 'store' channel, i_brand_id,i_class_id
  190. ,i_category_id, sum(ss_quantity*ss_list_price) sales, count(*) number_sales
  191. from store_sales
  192. ,item
  193. ,date_dim
  194. where ss_item_sk in (select ss_item_sk from cross_items)
  195. and ss_item_sk = i_item_sk
  196. and ss_sold_date_sk = d_date_sk
  197. and d_week_seq = (select d_week_seq
  198. from date_dim
  199. where d_year = 2000
  200. and d_moy = 12
  201. and d_dom = 15)
  202. group by i_brand_id,i_class_id,i_category_id
  203. having sum(ss_quantity*ss_list_price) > (select average_sales from avg_sales)) last_year
  204. where this_year.i_brand_id= last_year.i_brand_id
  205. and this_year.i_class_id = last_year.i_class_id
  206. and this_year.i_category_id = last_year.i_category_id
  207. order by this_year.channel, this_year.i_brand_id, this_year.i_class_id, this_year.i_category_id
  208. limit 100;
  209. -- end query 1 in stream 0 using template query14.tpl