diff --git a/tables/lastpricedetail.ms.sql b/tables/lastpricedetail.ms.sql index c1d92b8..885043b 100644 --- a/tables/lastpricedetail.ms.sql +++ b/tables/lastpricedetail.ms.sql @@ -51,42 +51,50 @@ WITH base AS ( ranked AS ( SELECT b.* - -- Most recent sale - ,ROW_NUMBER() OVER ( + -- Most recent sale (Actuals only) + ,CASE WHEN b.version = 'Actual' THEN + ROW_NUMBER() OVER ( PARTITION BY b.customer, b.partgroup - ORDER BY CASE WHEN b.version = 'Actual' THEN b.odate ELSE NULL END DESC - ) AS rn_mrs - -- Most recent quote - ,ROW_NUMBER() OVER ( + ORDER BY b.odate DESC + ) + END AS rn_mrs + -- Most recent quote (Quotes only) + ,CASE WHEN b.version = 'Quotes' THEN + ROW_NUMBER() OVER ( PARTITION BY b.customer, b.partgroup - ORDER BY CASE WHEN b.version = 'Quotes' THEN b.odate ELSE NULL END DESC - ) AS rn_mrq - -- Largest volume sale (last 12 months) - ,ROW_NUMBER() OVER ( + ORDER BY b.odate DESC + ) + END AS rn_mrq + -- Largest volume sale (Actuals only; last 12 months prioritized) + ,CASE WHEN b.version = 'Actual' THEN + ROW_NUMBER() OVER ( PARTITION BY b.customer, b.partgroup - ORDER BY CASE - WHEN b.version = 'Actual' AND b.odate >= DATEADD(YEAR, -1, GETDATE()) - THEN b.qty ELSE NULL - END DESC - ) AS rn_lvs - -- Largest volume quote (last 12 months) - ,ROW_NUMBER() OVER ( + ORDER BY + CASE WHEN b.version = 'Actual' AND b.odate >= DATEADD(YEAR, -1, GETDATE()) THEN 1 ELSE 0 END DESC, + b.qty DESC + ) + END AS rn_lvs + -- Largest volume quote (Quotes only; last 12 months prioritized) + ,CASE WHEN b.version = 'Quotes' THEN + ROW_NUMBER() OVER ( PARTITION BY b.customer, b.partgroup - ORDER BY CASE - WHEN b.version = 'Quotes' AND b.odate >= DATEADD(YEAR, -1, GETDATE()) - THEN b.qty ELSE NULL - END DESC - ) AS rn_lvq - -- Most recent sale per data segment - ,ROW_NUMBER() OVER ( + ORDER BY + CASE WHEN b.version = 'Quotes' AND b.odate >= DATEADD(YEAR, -1, GETDATE()) THEN 1 ELSE 0 END DESC, + b.qty DESC + ) + END AS rn_lvq + ,CASE WHEN b.version = 'Actual' THEN + ROW_NUMBER() OVER ( PARTITION BY b.customer, b.partgroup, b.dataseg, b.version - ORDER BY CASE WHEN b.version = 'Actual' THEN b.odate ELSE NULL END DESC - ) AS rn_dss - -- Most recent quote per data segment - ,ROW_NUMBER() OVER ( + ORDER BY b.odate DESC + ) + END AS rn_dss + ,CASE WHEN b.version = 'Quotes' THEN + ROW_NUMBER() OVER ( PARTITION BY b.customer, b.partgroup, b.dataseg, b.version - ORDER BY CASE WHEN b.version = 'Quotes' THEN b.odate ELSE NULL END DESC - ) AS rn_dsq + ORDER BY b.odate DESC + ) + END AS rn_dsq FROM base b ) -------------------------------------------------------------------------------- @@ -121,7 +129,7 @@ ON #flagged(customer, partgroup, dataseg, version, part, qty, price, odate, ordn -- Step 3.1: Explode all flags from the #flagged table WITH exploded_flags AS ( SELECT - customer, partgroup, part, dataseg, version, part, qty, price, odate, ordnum, quoten, + customer, partgroup, part, dataseg, version, qty, price, odate, ordnum, quoten, flag FROM #flagged CROSS APPLY (VALUES (f1), (f2), (f3), (f4), (f5), (f6)) AS f(flag)