work on filter before row number

This commit is contained in:
Paul Trowbridge 2025-09-04 15:04:30 -04:00
parent a5a746c005
commit abac006970

View File

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