diff --git a/tables/lastpricedetail.pg.sql b/tables/lastpricedetail.pg.sql index 5ab8494..507ffe1 100644 --- a/tables/lastpricedetail.pg.sql +++ b/tables/lastpricedetail.pg.sql @@ -1,5 +1,7 @@ REFRESH MATERIALIZED VIEW pricequote.lastpricedetail; +--DROP MATERIALIZED VIEW pricequote.lastpricedetail + CREATE MATERIALIZED VIEW pricequote.lastpricedetail AS WITH base AS ( SELECT @@ -23,32 +25,41 @@ WITH base AS ( AND version IN ('Actual', 'Quotes') ), ranked AS ( - SELECT *, - ROW_NUMBER() OVER ( - PARTITION BY customer, partgroup - ORDER BY CASE WHEN version = 'Actual' THEN odate END DESC - ) AS rn_mrs, - ROW_NUMBER() OVER ( - PARTITION BY customer, partgroup - ORDER BY CASE WHEN version = 'Quotes' THEN odate END DESC - ) AS rn_mrq, - ROW_NUMBER() OVER ( - PARTITION BY customer, partgroup - ORDER BY CASE WHEN version = 'Actual' AND odate >= (CURRENT_DATE - INTERVAL '1 year') THEN qty END DESC - ) AS rn_lvs, - ROW_NUMBER() OVER ( - PARTITION BY customer, partgroup - ORDER BY CASE WHEN version = 'Quotes' AND odate >= (CURRENT_DATE - INTERVAL '1 year') THEN qty END DESC - ) AS rn_lvq, - ROW_NUMBER() OVER ( - PARTITION BY customer, partgroup, dataseg, version - ORDER BY CASE WHEN version = 'Actual' THEN odate END DESC - ) AS rn_dss, - ROW_NUMBER() OVER ( - PARTITION BY customer, partgroup, dataseg, version - ORDER BY CASE WHEN version = 'Quotes' THEN odate END DESC - ) AS rn_dsq - FROM base + SELECT b.*, + -- Most recent sale (Actuals first, newest date first) + ROW_NUMBER() OVER ( + PARTITION BY customer, partgroup + ORDER BY (version = 'Actual') DESC, + odate DESC NULLS LAST + ) AS rn_mrs, + -- Most recent quote (Quotes first, newest date first) + ROW_NUMBER() OVER ( + PARTITION BY customer, partgroup + ORDER BY (version = 'Quotes') DESC, + odate DESC NULLS LAST + ) AS rn_mrq, + -- Largest volume sale in last year (those inside window first) + ROW_NUMBER() OVER ( + PARTITION BY customer, partgroup + ORDER BY (version = 'Actual' AND odate >= CURRENT_DATE - INTERVAL '1 year') DESC, + qty DESC NULLS LAST + ) AS rn_lvs, + -- Largest volume quote in last year (those inside window first) + ROW_NUMBER() OVER ( + PARTITION BY customer, partgroup + ORDER BY (version = 'Quotes' AND odate >= CURRENT_DATE - INTERVAL '1 year') DESC, + qty DESC NULLS LAST + ) AS rn_lvq, + -- Per dataseg/version: most recent (version fixed in partition, so just date) + ROW_NUMBER() OVER ( + PARTITION BY customer, partgroup, dataseg, version + ORDER BY odate DESC NULLS LAST + ) AS rn_dss, + ROW_NUMBER() OVER ( + PARTITION BY customer, partgroup, dataseg, version + ORDER BY odate DESC NULLS LAST + ) AS rn_dsq + FROM base b ), flagged AS ( SELECT *, @@ -62,6 +73,7 @@ flagged AS ( WHERE rn_mrs = 1 OR rn_mrq = 1 OR rn_lvs = 1 OR rn_lvq = 1 OR rn_dss = 1 OR rn_dsq = 1 ), +--SELECT * FROM flagged WHERE customer = 'HYBELS' AND partgroup = 'HZP3E100' exploded_flags AS ( SELECT customer, partgroup, dataseg, version, qty, price, odate, ordnum, quoten,