From 8b6df1c9175b4c0e96ae08b63a122c9b22eff378 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Wed, 6 Aug 2025 11:23:40 -0400 Subject: [PATCH] new last price schema --- new_targets/tables/lastpricedetail.ms.sql | 160 +++++++++++----------- 1 file changed, 77 insertions(+), 83 deletions(-) diff --git a/new_targets/tables/lastpricedetail.ms.sql b/new_targets/tables/lastpricedetail.ms.sql index 1eb4c2d..809e41f 100644 --- a/new_targets/tables/lastpricedetail.ms.sql +++ b/new_targets/tables/lastpricedetail.ms.sql @@ -1,12 +1,13 @@ -------------------------------------------------------------------------------- --- Clear old data +-- Reset target tables -------------------------------------------------------------------------------- -DROP TABLE IF EXISTS pricing.lastpricedetail; +--DROP TABLE IF EXISTS pricing.lastpricedetail; DELETE FROM pricing.lastpricedetail; DROP TABLE IF EXISTS #flagged; -------------------------------------------------------------------------------- --- Base cleaned input +-- Stage 1: Load cleaned input rows +-- Filters out irrelevant quotes/orders and calculates unit prices -------------------------------------------------------------------------------- WITH base AS ( SELECT @@ -34,25 +35,33 @@ WITH base AS ( AND o."Order Status" <> 'CANCELLED' AND o."Units" > 0 AND o."Part Group" <> '' + -- Optional filter for testing -- AND o."Customer" = 'ESBENSHADES GREENHOUSE' ), -------------------------------------------------------------------------------- --- Rank rows for recency and volume +-- Stage 2: Rank each row based on recency and volume rules +-- Flags include: +-- - rn_mrs: most recent sale +-- - rn_mrq: most recent quote +-- - rn_lvs: largest sale in last year +-- - rn_lvq: largest quote in last year +-- - rn_dss: most recent sale per dataseg +-- - rn_dsq: most recent quote per dataseg -------------------------------------------------------------------------------- ranked AS ( SELECT b.* - -- most recent sale + -- Most recent sale ,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 + -- Most recent quote ,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 + -- Largest volume sale (last 12 months) ,ROW_NUMBER() OVER ( PARTITION BY b.customer, b.partgroup ORDER BY CASE @@ -60,7 +69,7 @@ ranked AS ( THEN b.qty ELSE NULL END DESC ) AS rn_lvs - -- largest volume quote + -- Largest volume quote (last 12 months) ,ROW_NUMBER() OVER ( PARTITION BY b.customer, b.partgroup ORDER BY CASE @@ -68,66 +77,63 @@ ranked AS ( THEN b.qty ELSE NULL END DESC ) AS rn_lvq - -- most recent sale for data segment + -- Most recent sale per data segment ,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 for data segment + -- Most recent quote per data segment ,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 FROM base b ) -SELECT * INTO #flagged FROM ranked +-------------------------------------------------------------------------------- +-- Stage 2.5: Save only rows that meet any of the above criteria +-- and annotate each with global-level flag (mrs, mrq, lvs, lvq) +-------------------------------------------------------------------------------- +SELECT + *, + CASE WHEN rn_mrs = 1 THEN 'mrs' END AS f1, + CASE WHEN rn_mrq = 1 THEN 'mrq' END AS f2, + CASE WHEN rn_lvs = 1 THEN 'lvs' END AS f3, + CASE WHEN rn_lvq = 1 THEN 'lvq' END AS f4, + CASE WHEN rn_dss = 1 THEN 'dss' END AS f5, + CASE WHEN rn_dsq = 1 THEN 'dsq' END AS f6 +INTO #flagged +FROM ranked WHERE - 1=1 - -- AND partgroup = 'XNS0T1G3' - AND ( - 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; CREATE NONCLUSTERED INDEX ix_flagged_lookup ON #flagged(customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten); ---SELECT * FROM #flagged WHERE customer LIKE 'ESBENSHADE%' AND partgroup = 'XNS0T1G3' - -------------------------------------------------------------------------------- --- Assumes you already have #flagged built from ranked rows --- with columns: customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten, --- and rank columns: rn_mrs, rn_mrq, rn_lvs, rn_lvq, rn_dss, rn_dsq +-- Stage 3: Build JSON from flagged rows -------------------------------------------------------------------------------- --- Step 1: Flatten flag-based records -WITH exploded AS ( - SELECT *, - CASE WHEN rn_mrs = 1 THEN 'mrs' END AS f1, - CASE WHEN rn_mrq = 1 THEN 'mrq' END AS f2, - CASE WHEN rn_lvs = 1 THEN 'lvs' END AS f3, - CASE WHEN rn_lvq = 1 THEN 'lvq' END AS f4 - FROM #flagged --- WHERE customer LIKE 'ESBENSHADE%' AND partgroup = 'XNS0T1G3' -) -,flags AS ( +-- Step 3.1: Explode all flags from the #flagged table +WITH exploded_flags AS ( SELECT customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten, flag - FROM exploded - CROSS APPLY (VALUES (f1), (f2), (f3), (f4)) AS f(flag) + FROM #flagged + CROSS APPLY (VALUES (f1), (f2), (f3), (f4), (f5), (f6)) AS f(flag) WHERE flag IS NOT NULL ) ---SELECT * FROM flags --- Step 2: JSON object for each flag (mrs/mrq/lvs/lvq) +--SELECT * FROM exploded_flags +-- Step 3.2: Serialize each row into its JSON snippet ,serialized_flags AS ( SELECT customer, partgroup, + dataseg, flag, CONCAT( '"', flag, '":', @@ -145,65 +151,58 @@ WITH exploded AS ( FOR JSON PATH, WITHOUT_ARRAY_WRAPPER )) ) AS json_piece - FROM flags + FROM exploded_flags ) +--SELECT * FROM serialized_flags +-- Step 3.3: Collect all global-level flags (mrs, mrq, lvs, lvq) ,flag_json AS ( SELECT customer, partgroup, STRING_AGG(json_piece, ',') AS json_block FROM serialized_flags + WHERE flag IN ('mrs', 'mrq', 'lvs', 'lvq') GROUP BY customer, partgroup ) --SELECT * FROM flag_json --- Step 3: One row per (customer, partgroup, dataseg) — most recent -,seg_rows AS ( - SELECT * - FROM ( - SELECT *, - ROW_NUMBER() OVER ( - PARTITION BY customer, partgroup, dataseg - ORDER BY odate DESC - ) AS rk - FROM #flagged --- WHERE customer LIKE 'ESBENSHADE%' AND partgroup = 'XNS0T1G3' - ) x - WHERE rk = 1 -) ---SELECT * FROM seg_rows --- Step 4: JSON object for each dataseg -, serialized_segs AS ( - SELECT +-- Step 3.4: Nest dss/dsq under each dataseg +,seg_pieces AS ( + SELECT customer, partgroup, dataseg, + STRING_AGG(json_piece, ',') AS inner_json + FROM serialized_flags + WHERE flag IN ('dss', 'dsq') + GROUP BY customer, partgroup, dataseg +) +--SELECT * FROM seg_pieces +-- Step 3.5: Wrap the inner_json under dataseg key +,wrapped_segs AS ( + SELECT + customer, + partgroup, CONCAT( - '"', dataseg, '":', - JSON_QUERY(( - SELECT - version, - dataseg AS datasegment, - part, - qty, - price, - odate, - ordnum, - quoten - FOR JSON PATH, WITHOUT_ARRAY_WRAPPER - )) + '"', dataseg, '": {', inner_json, '}' ) AS json_piece - FROM seg_rows -), -seg_json AS ( + FROM seg_pieces +) +-- Step 3.6: Aggregate all dataseg entries into one JSON block per customer/partgroup +,seg_json AS ( SELECT customer, partgroup, STRING_AGG(json_piece, ',') AS json_block - FROM serialized_segs + FROM wrapped_segs GROUP BY customer, partgroup ) --SELECT * FROM seg_json --- Step 5: Merge into final JSON per (customer, partgroup) +-------------------------------------------------------------------------------- +-- Stage 4: Merge flags and segment blocks into a single JSON object +-- Write final pricing history to pricing.lastpricedetail +-------------------------------------------------------------------------------- +INSERT INTO + pricing.lastpricedetail SELECT COALESCE(f.customer, s.customer) AS customer, COALESCE(f.partgroup, s.partgroup) AS partgroup, @@ -217,11 +216,6 @@ SELECT COALESCE(s.json_block, ''), '}' ) AS part_stats -INTO #final_json FROM flag_json f FULL OUTER JOIN seg_json s ON f.customer = s.customer AND f.partgroup = s.partgroup; --- Final output - -SELECT * FROM #FINAL_JSON WHERE customer = 'GRIFFIN' AND partgroup = 'XNS0T1G3' -