query51.sql 1.6 KB

123456789101112131415161718192021222324252627282930313233343536373839404142
  1. WITH web_v1 as (
  2. select
  3. ws_item_sk item_sk, d_date, sum(ws_sales_price),
  4. sum(sum(ws_sales_price))
  5. over (partition by ws_item_sk order by d_date rows between unbounded preceding and current row) cume_sales
  6. from web_sales
  7. ,date_dim
  8. where ws_sold_date_sk=d_date_sk
  9. and d_month_seq between 1193 and 1193+11
  10. and ws_item_sk is not NULL
  11. group by ws_item_sk, d_date),
  12. store_v1 as (
  13. select
  14. ss_item_sk item_sk, d_date, sum(ss_sales_price),
  15. sum(sum(ss_sales_price))
  16. over (partition by ss_item_sk order by d_date rows between unbounded preceding and current row) cume_sales
  17. from store_sales
  18. ,date_dim
  19. where ss_sold_date_sk=d_date_sk
  20. and d_month_seq between 1193 and 1193+11
  21. and ss_item_sk is not NULL
  22. group by ss_item_sk, d_date)
  23. select *
  24. from (select item_sk
  25. ,d_date
  26. ,web_sales
  27. ,store_sales
  28. ,max(web_sales)
  29. over (partition by item_sk order by d_date rows between unbounded preceding and current row) web_cumulative
  30. ,max(store_sales)
  31. over (partition by item_sk order by d_date rows between unbounded preceding and current row) store_cumulative
  32. from (select case when web.item_sk is not null then web.item_sk else store.item_sk end item_sk
  33. ,case when web.d_date is not null then web.d_date else store.d_date end d_date
  34. ,web.cume_sales web_sales
  35. ,store.cume_sales store_sales
  36. from web_v1 web full outer join store_v1 store on (web.item_sk = store.item_sk
  37. and web.d_date = store.d_date)
  38. )x )y
  39. where web_cumulative > store_cumulative
  40. order by item_sk
  41. ,d_date
  42. limit 100;