WITH srt AS ( SELECT customer, mold, part, qty, ROUND(sales_usd / qty, 5) AS price, odate, oseas, ordnum, quoten, ROW_NUMBER() OVER ( PARTITION BY customer, mold, part ORDER BY odate DESC ) AS rn FROM rlarp.osm_stack WHERE version = 'Actual' AND customer IS NOT NULL AND fs_line = '41010' AND calc_status <> 'CANCELLED' AND qty <> 0 AND mold <> '' ), json_rows AS ( SELECT customer, mold, part, CONCAT( '"', part, '":', ( SELECT qty, price, odate, ordnum, quoten FOR JSON PATH, WITHOUT_ARRAY_WRAPPER ) ) AS part_json FROM srt WHERE rn = 1 ) ,onerow AS ( SELECT customer, mold, CONCAT('{', STRING_AGG(part_json, ','), '}') AS part_stats FROM json_rows GROUP BY customer, mold ) SELECT * INTO #lastprice FROM onerow SELECT count(*) FROM rlarp.osm_stack o INNER JOIN #lastprice l ON l.customer = o.customer AND o.mold = l.mold SELECT * FROM #lastprice SELECT o.ordnum, o.part, o.odate, lp.customer, lp.mold, p.[key] AS part, -- this is the part number j.qty, j.price, j.odate, j.ordnum, j.quoten FROM rlarp.osm_stack o LEFT OUTER JOIN #lastprice lp ON lp.customer = o.customer AND lp.mold = o.mold CROSS APPLY OPENJSON(lp.part_stats) AS p -- unpacks part keys CROSS APPLY OPENJSON(p.value) WITH ( qty FLOAT, price FLOAT, odate DATE, ordnum INT, quoten INT ) AS j WHERE o.customer = 'ALTMAN PLANTS' AND o.mold = 'XPR15CS1'