q14a.sql 3.6 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120
  1. WITH cross_items AS
  2. (SELECT i_item_sk ss_item_sk
  3. FROM item,
  4. (SELECT
  5. iss.i_brand_id brand_id,
  6. iss.i_class_id class_id,
  7. iss.i_category_id category_id
  8. FROM store_sales, item iss, date_dim d1
  9. WHERE ss_item_sk = iss.i_item_sk
  10. AND ss_sold_date_sk = d1.d_date_sk
  11. AND d1.d_year BETWEEN 1999 AND 1999 + 2
  12. INTERSECT
  13. SELECT
  14. ics.i_brand_id,
  15. ics.i_class_id,
  16. ics.i_category_id
  17. FROM catalog_sales, item ics, date_dim d2
  18. WHERE cs_item_sk = ics.i_item_sk
  19. AND cs_sold_date_sk = d2.d_date_sk
  20. AND d2.d_year BETWEEN 1999 AND 1999 + 2
  21. INTERSECT
  22. SELECT
  23. iws.i_brand_id,
  24. iws.i_class_id,
  25. iws.i_category_id
  26. FROM web_sales, item iws, date_dim d3
  27. WHERE ws_item_sk = iws.i_item_sk
  28. AND ws_sold_date_sk = d3.d_date_sk
  29. AND d3.d_year BETWEEN 1999 AND 1999 + 2) x
  30. WHERE i_brand_id = brand_id
  31. AND i_class_id = class_id
  32. AND i_category_id = category_id
  33. ),
  34. avg_sales AS
  35. (SELECT avg(quantity * list_price) average_sales
  36. FROM (
  37. SELECT
  38. ss_quantity quantity,
  39. ss_list_price list_price
  40. FROM store_sales, date_dim
  41. WHERE ss_sold_date_sk = d_date_sk
  42. AND d_year BETWEEN 1999 AND 2001
  43. UNION ALL
  44. SELECT
  45. cs_quantity quantity,
  46. cs_list_price list_price
  47. FROM catalog_sales, date_dim
  48. WHERE cs_sold_date_sk = d_date_sk
  49. AND d_year BETWEEN 1999 AND 1999 + 2
  50. UNION ALL
  51. SELECT
  52. ws_quantity quantity,
  53. ws_list_price list_price
  54. FROM web_sales, date_dim
  55. WHERE ws_sold_date_sk = d_date_sk
  56. AND d_year BETWEEN 1999 AND 1999 + 2) x)
  57. SELECT
  58. channel,
  59. i_brand_id,
  60. i_class_id,
  61. i_category_id,
  62. sum(sales),
  63. sum(number_sales)
  64. FROM (
  65. SELECT
  66. 'store' channel,
  67. i_brand_id,
  68. i_class_id,
  69. i_category_id,
  70. sum(ss_quantity * ss_list_price) sales,
  71. count(*) number_sales
  72. FROM store_sales, item, date_dim
  73. WHERE ss_item_sk IN (SELECT ss_item_sk
  74. FROM cross_items)
  75. AND ss_item_sk = i_item_sk
  76. AND ss_sold_date_sk = d_date_sk
  77. AND d_year = 1999 + 2
  78. AND d_moy = 11
  79. GROUP BY i_brand_id, i_class_id, i_category_id
  80. HAVING sum(ss_quantity * ss_list_price) > (SELECT average_sales
  81. FROM avg_sales)
  82. UNION ALL
  83. SELECT
  84. 'catalog' channel,
  85. i_brand_id,
  86. i_class_id,
  87. i_category_id,
  88. sum(cs_quantity * cs_list_price) sales,
  89. count(*) number_sales
  90. FROM catalog_sales, item, date_dim
  91. WHERE cs_item_sk IN (SELECT ss_item_sk
  92. FROM cross_items)
  93. AND cs_item_sk = i_item_sk
  94. AND cs_sold_date_sk = d_date_sk
  95. AND d_year = 1999 + 2
  96. AND d_moy = 11
  97. GROUP BY i_brand_id, i_class_id, i_category_id
  98. HAVING sum(cs_quantity * cs_list_price) > (SELECT average_sales FROM avg_sales)
  99. UNION ALL
  100. SELECT
  101. 'web' channel,
  102. i_brand_id,
  103. i_class_id,
  104. i_category_id,
  105. sum(ws_quantity * ws_list_price) sales,
  106. count(*) number_sales
  107. FROM web_sales, item, date_dim
  108. WHERE ws_item_sk IN (SELECT ss_item_sk
  109. FROM cross_items)
  110. AND ws_item_sk = i_item_sk
  111. AND ws_sold_date_sk = d_date_sk
  112. AND d_year = 1999 + 2
  113. AND d_moy = 11
  114. GROUP BY i_brand_id, i_class_id, i_category_id
  115. HAVING sum(ws_quantity * ws_list_price) > (SELECT average_sales
  116. FROM avg_sales)
  117. ) y
  118. GROUP BY ROLLUP (channel, i_brand_id, i_class_id, i_category_id)
  119. ORDER BY channel, i_brand_id, i_class_id, i_category_id
  120. LIMIT 100