1
0

query64.sql 3.6 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121
  1. -- start query 1 in stream 0 using template query64.tpl and seed 1220860970
  2. with cs_ui as
  3. (select cs_item_sk
  4. ,sum(cs_ext_list_price) as sale,sum(cr_refunded_cash+cr_reversed_charge+cr_store_credit) as refund
  5. from catalog_sales
  6. ,catalog_returns
  7. where cs_item_sk = cr_item_sk
  8. and cs_order_number = cr_order_number
  9. group by cs_item_sk
  10. having sum(cs_ext_list_price)>2*sum(cr_refunded_cash+cr_reversed_charge+cr_store_credit)),
  11. cross_sales as
  12. (select i_product_name product_name
  13. ,i_item_sk item_sk
  14. ,s_store_name store_name
  15. ,s_zip store_zip
  16. ,ad1.ca_street_number b_street_number
  17. ,ad1.ca_street_name b_street_name
  18. ,ad1.ca_city b_city
  19. ,ad1.ca_zip b_zip
  20. ,ad2.ca_street_number c_street_number
  21. ,ad2.ca_street_name c_street_name
  22. ,ad2.ca_city c_city
  23. ,ad2.ca_zip c_zip
  24. ,d1.d_year as syear
  25. ,d2.d_year as fsyear
  26. ,d3.d_year s2year
  27. ,count(*) cnt
  28. ,sum(ss_wholesale_cost) s1
  29. ,sum(ss_list_price) s2
  30. ,sum(ss_coupon_amt) s3
  31. FROM store_sales
  32. ,store_returns
  33. ,cs_ui
  34. ,date_dim d1
  35. ,date_dim d2
  36. ,date_dim d3
  37. ,store
  38. ,customer
  39. ,customer_demographics cd1
  40. ,customer_demographics cd2
  41. ,promotion
  42. ,household_demographics hd1
  43. ,household_demographics hd2
  44. ,customer_address ad1
  45. ,customer_address ad2
  46. ,income_band ib1
  47. ,income_band ib2
  48. ,item
  49. WHERE ss_store_sk = s_store_sk AND
  50. ss_sold_date_sk = d1.d_date_sk AND
  51. ss_customer_sk = c_customer_sk AND
  52. ss_cdemo_sk= cd1.cd_demo_sk AND
  53. ss_hdemo_sk = hd1.hd_demo_sk AND
  54. ss_addr_sk = ad1.ca_address_sk and
  55. ss_item_sk = i_item_sk and
  56. ss_item_sk = sr_item_sk and
  57. ss_ticket_number = sr_ticket_number and
  58. ss_item_sk = cs_ui.cs_item_sk and
  59. c_current_cdemo_sk = cd2.cd_demo_sk AND
  60. c_current_hdemo_sk = hd2.hd_demo_sk AND
  61. c_current_addr_sk = ad2.ca_address_sk and
  62. c_first_sales_date_sk = d2.d_date_sk and
  63. c_first_shipto_date_sk = d3.d_date_sk and
  64. ss_promo_sk = p_promo_sk and
  65. hd1.hd_income_band_sk = ib1.ib_income_band_sk and
  66. hd2.hd_income_band_sk = ib2.ib_income_band_sk and
  67. cd1.cd_marital_status <> cd2.cd_marital_status and
  68. i_color in ('azure','gainsboro','misty','blush','hot','lemon') and
  69. i_current_price between 80 and 80 + 10 and
  70. i_current_price between 80 + 1 and 80 + 15
  71. group by i_product_name
  72. ,i_item_sk
  73. ,s_store_name
  74. ,s_zip
  75. ,ad1.ca_street_number
  76. ,ad1.ca_street_name
  77. ,ad1.ca_city
  78. ,ad1.ca_zip
  79. ,ad2.ca_street_number
  80. ,ad2.ca_street_name
  81. ,ad2.ca_city
  82. ,ad2.ca_zip
  83. ,d1.d_year
  84. ,d2.d_year
  85. ,d3.d_year
  86. )
  87. select cs1.product_name
  88. ,cs1.store_name
  89. ,cs1.store_zip
  90. ,cs1.b_street_number
  91. ,cs1.b_street_name
  92. ,cs1.b_city
  93. ,cs1.b_zip
  94. ,cs1.c_street_number
  95. ,cs1.c_street_name
  96. ,cs1.c_city
  97. ,cs1.c_zip
  98. ,cs1.syear
  99. ,cs1.cnt
  100. ,cs1.s1 as s11
  101. ,cs1.s2 as s21
  102. ,cs1.s3 as s31
  103. ,cs2.s1 as s12
  104. ,cs2.s2 as s22
  105. ,cs2.s3 as s32
  106. ,cs2.syear
  107. ,cs2.cnt
  108. from cross_sales cs1,cross_sales cs2
  109. where cs1.item_sk=cs2.item_sk and
  110. cs1.syear = 1999 and
  111. cs2.syear = 1999 + 1 and
  112. cs2.cnt <= cs1.cnt and
  113. cs1.store_name = cs2.store_name and
  114. cs1.store_zip = cs2.store_zip
  115. order by cs1.product_name
  116. ,cs1.store_name
  117. ,cs2.cnt
  118. ,cs1.s1
  119. ,cs2.s1;
  120. -- end query 1 in stream 0 using template query64.tpl