-------------------------------------------------------------------------------- -- Reset target tables -------------------------------------------------------------------------------- --DROP TABLE IF EXISTS pricing.lastpricedetail; DELETE FROM pricing.lastpricedetail; DROP TABLE IF EXISTS #flagged; -------------------------------------------------------------------------------- -- Stage 1: Load cleaned input rows -- Filters out irrelevant quotes/orders and calculates unit prices -------------------------------------------------------------------------------- WITH base AS ( SELECT o."Customer" AS customer, o."Part Group" AS partgroup, RTRIM(i.V1DS) AS dataseg, o."Data Source" AS version, o."Part Code" AS part, o."Units" AS qty, CASE WHEN o."Units" = 0 THEN NULL ELSE ROUND(o.[Value USD] / NULLIF(o."Units", 0), 5) END AS price, o.[Order Date] AS odate, o.[Order Number] AS ordnum, o.[Quote Number] AS quoten FROM rlarp.osm_stack_pretty o INNER JOIN CMSInterfaceIn.[CMS.CUSLG].ITEMM i ON i.item = o.[Part Code] WHERE o.[Data Source] IN ('Actual', 'Quotes') AND o."Customer" IS NOT NULL AND o."Financial Statement Line" = '41010' AND o."Order Status" <> 'CANCELLED' AND o."Units" > 0 AND o."Part Group" <> '' -- Optional filter for testing -- AND o."Customer" = 'ESBENSHADES GREENHOUSE' ), -------------------------------------------------------------------------------- -- 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 ,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 ( 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 ( 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 ( 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 ( 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 ( 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 ) -------------------------------------------------------------------------------- -- 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 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); -------------------------------------------------------------------------------- -- Stage 3: Build JSON from flagged rows -------------------------------------------------------------------------------- -- 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 #flagged CROSS APPLY (VALUES (f1), (f2), (f3), (f4), (f5), (f6)) AS f(flag) WHERE flag IS NOT NULL ) --SELECT * FROM exploded_flags -- Step 3.2: Serialize each row into its JSON snippet ,serialized_flags AS ( SELECT customer, partgroup, dataseg, flag, CONCAT( '"', flag, '":', JSON_QUERY(( SELECT version, dataseg AS datasegment, part, qty, price, odate, ordnum, quoten, flag FOR JSON PATH, WITHOUT_ARRAY_WRAPPER )) ) AS json_piece 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.4: Nest dss/dsq under each dataseg -- Only keep the most recent dss/dsq per dataseg/version (prevents duplicate keys) ,seg_pieces AS ( SELECT customer, partgroup, dataseg, STRING_AGG(json_piece, ',') AS inner_json FROM ( SELECT sf.* FROM ( SELECT *, ROW_NUMBER() OVER ( PARTITION BY customer, partgroup, dataseg, flag ORDER BY odate DESC, version DESC -- prefer most recent, then prefer 'Actual' over 'Quotes' ) AS rn FROM serialized_flags WHERE flag IN ('dss', 'dsq') ) sf WHERE sf.rn = 1 ) deduped 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, '": {', inner_json, '}' ) AS json_piece 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 wrapped_segs GROUP BY customer, partgroup ) --SELECT * FROM seg_json -------------------------------------------------------------------------------- -- 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, CONCAT( '{', COALESCE(f.json_block, ''), CASE WHEN f.json_block IS NOT NULL AND s.json_block IS NOT NULL THEN ',' ELSE '' END, COALESCE(s.json_block, ''), '}' ) AS part_stats FROM flag_json f FULL OUTER JOIN seg_json s ON f.customer = s.customer AND f.partgroup = s.partgroup;