q14.sql 7.8 KB

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