-------------------------------------------------------------------------------- -- Step 1: Rebuild last price history at sales matrix refresh time -------------------------------------------------------------------------------- DELETE FROM pricing.lastprice; WITH --------SORT-------- srt AS ( SELECT o."Customer" customer, o."Part Group" partgroup, RTRIM(i.V1DS) dataseg, o."Data Source" version, o."Part Code" part, o."Units" qty, ROUND(o.[Value USD] / o.[Units], 5) AS price, o.[Order Date] odate, o.[Order Season] oseas, o.[Order Number] ordnum, o.[Quote Number] quoten, ROW_NUMBER() OVER ( PARTITION BY o.Customer , o.[Part Group] , i.V1DS, o.[Data Source] ORDER BY o."Order Date" DESC ) AS rn FROM rlarp.osm_stack_pretty o INNER JOIN CMSInterfaceIn.[CMS.CUSLG].ITEMM i ON i.item = o.[Part Code] WHERE --quotes can't be integrated until we have datasegment or correct part code o.[Data Source] IN ('Actual'/*,'Quotes'*/) AND customer IS NOT NULL AND [Financial Statement Line] = '41010' AND o.[Order Status] <> 'CANCELLED' AND o.Units <> 0 AND o.[Part Group] <> '' ), json_rows AS ( SELECT customer, partgroup, dataseg, version, CONCAT( '"', dataseg, '":', ( SELECT version, part, qty, price, odate, ordnum, quoten FOR JSON PATH, WITHOUT_ARRAY_WRAPPER ) ) AS part_json FROM srt WHERE rn = 1 ) ,onerow AS ( SELECT customer, partgroup, CONCAT('{', STRING_AGG(part_json, ','), '}') AS part_stats FROM json_rows GROUP BY customer, partgroup ) --SELECT * INTO pricing.lastprice FROM onerow; INSERT INTO pricing.lastprice SELECT * FROM onerow; --SELECT * FROM pricing.lastprice l CREATE UNIQUE INDEX lastprice_cust_partgroup ON pricing.lastprice(customer, partgroup);