-------------------------------------------------------------------------------- -- Clear old data -------------------------------------------------------------------------------- DROP TABLE IF EXISTS pricing.lastpricedetail; DELETE FROM pricing.lastpricedetail; DROP TABLE IF EXISTS #flagged; -------------------------------------------------------------------------------- -- Base cleaned input -------------------------------------------------------------------------------- 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" <> '' -- AND o."Customer" = 'ESBENSHADES GREENHOUSE' ), -------------------------------------------------------------------------------- -- Rank rows for recency and volume -------------------------------------------------------------------------------- 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 ,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 ,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 for 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 ,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 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 ) 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 -------------------------------------------------------------------------------- -- 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 ( SELECT customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten, flag FROM exploded CROSS APPLY (VALUES (f1), (f2), (f3), (f4)) AS f(flag) WHERE flag IS NOT NULL ) --SELECT * FROM flags -- Step 2: JSON object for each flag (mrs/mrq/lvs/lvq) ,serialized_flags AS ( SELECT customer, partgroup, 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 flags ) ,flag_json AS ( SELECT customer, partgroup, STRING_AGG(json_piece, ',') AS json_block FROM serialized_flags 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 customer, partgroup, dataseg, CONCAT( '"', dataseg, '":', JSON_QUERY(( SELECT version, dataseg AS datasegment, part, qty, price, odate, ordnum, quoten FOR JSON PATH, WITHOUT_ARRAY_WRAPPER )) ) AS json_piece FROM seg_rows ), seg_json AS ( SELECT customer, partgroup, STRING_AGG(json_piece, ',') AS json_block FROM serialized_segs GROUP BY customer, partgroup ) --SELECT * FROM seg_json -- Step 5: Merge into final JSON per (customer, partgroup) 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 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'