change last sale price flagging

This commit is contained in:
Paul Trowbridge 2025-08-11 09:50:37 -04:00
parent c423116b9d
commit 310f1dc8f9

View File

@ -1,5 +1,7 @@
REFRESH MATERIALIZED VIEW pricequote.lastpricedetail; REFRESH MATERIALIZED VIEW pricequote.lastpricedetail;
--DROP MATERIALIZED VIEW pricequote.lastpricedetail
CREATE MATERIALIZED VIEW pricequote.lastpricedetail AS CREATE MATERIALIZED VIEW pricequote.lastpricedetail AS
WITH base AS ( WITH base AS (
SELECT SELECT
@ -23,32 +25,41 @@ WITH base AS (
AND version IN ('Actual', 'Quotes') AND version IN ('Actual', 'Quotes')
), ),
ranked AS ( ranked AS (
SELECT *, SELECT b.*,
ROW_NUMBER() OVER ( -- Most recent sale (Actuals first, newest date first)
PARTITION BY customer, partgroup ROW_NUMBER() OVER (
ORDER BY CASE WHEN version = 'Actual' THEN odate END DESC PARTITION BY customer, partgroup
) AS rn_mrs, ORDER BY (version = 'Actual') DESC,
ROW_NUMBER() OVER ( odate DESC NULLS LAST
PARTITION BY customer, partgroup ) AS rn_mrs,
ORDER BY CASE WHEN version = 'Quotes' THEN odate END DESC -- Most recent quote (Quotes first, newest date first)
) AS rn_mrq, ROW_NUMBER() OVER (
ROW_NUMBER() OVER ( PARTITION BY customer, partgroup
PARTITION BY customer, partgroup ORDER BY (version = 'Quotes') DESC,
ORDER BY CASE WHEN version = 'Actual' AND odate >= (CURRENT_DATE - INTERVAL '1 year') THEN qty END DESC odate DESC NULLS LAST
) AS rn_lvs, ) AS rn_mrq,
ROW_NUMBER() OVER ( -- Largest volume sale in last year (those inside window first)
PARTITION BY customer, partgroup ROW_NUMBER() OVER (
ORDER BY CASE WHEN version = 'Quotes' AND odate >= (CURRENT_DATE - INTERVAL '1 year') THEN qty END DESC PARTITION BY customer, partgroup
) AS rn_lvq, ORDER BY (version = 'Actual' AND odate >= CURRENT_DATE - INTERVAL '1 year') DESC,
ROW_NUMBER() OVER ( qty DESC NULLS LAST
PARTITION BY customer, partgroup, dataseg, version ) AS rn_lvs,
ORDER BY CASE WHEN version = 'Actual' THEN odate END DESC -- Largest volume quote in last year (those inside window first)
) AS rn_dss, ROW_NUMBER() OVER (
ROW_NUMBER() OVER ( PARTITION BY customer, partgroup
PARTITION BY customer, partgroup, dataseg, version ORDER BY (version = 'Quotes' AND odate >= CURRENT_DATE - INTERVAL '1 year') DESC,
ORDER BY CASE WHEN version = 'Quotes' THEN odate END DESC qty DESC NULLS LAST
) AS rn_dsq ) AS rn_lvq,
FROM base -- 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 ( flagged AS (
SELECT *, SELECT *,
@ -62,6 +73,7 @@ flagged AS (
WHERE WHERE
rn_mrs = 1 OR rn_mrq = 1 OR rn_lvs = 1 OR rn_lvq = 1 OR rn_dss = 1 OR rn_dsq = 1 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 ( exploded_flags AS (
SELECT SELECT
customer, partgroup, dataseg, version, qty, price, odate, ordnum, quoten, customer, partgroup, dataseg, version, qty, price, odate, ordnum, quoten,