-------------------------------------------------------------------------------- -- 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); -------------------------------------------------------------------------------- -- Step 1: Rebuild last price history with flags for recency & feature-match -------------------------------------------------------------------------------- -------------------------------------------------------------------------------- -- Step 1: Rebuild last price history with global recency + part-level feature match -------------------------------------------------------------------------------- DELETE FROM pricing.lastprice; WITH base AS ( SELECT o."Customer" AS customer, o."Part Group" AS partgroup, RTRIM(i.V1DS) AS dataseg, o."Data Source" AS version, -- 'Actual' or 'Quotes' o."Part Code" AS part, o."Units" AS qty, ROUND(o.[Value USD] / o.[Units], 5) 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" <> '' ), ranked AS ( SELECT b.*, 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_recent_sale, 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_recent_quote FROM base b ), last_feature_sale AS ( SELECT * FROM ( SELECT *, ROW_NUMBER() OVER ( PARTITION BY customer, partgroup, part ORDER BY odate DESC ) AS rn FROM base WHERE version = 'Actual' ) x WHERE rn = 1 ), last_feature_quote AS ( SELECT * FROM ( SELECT *, ROW_NUMBER() OVER ( PARTITION BY customer, partgroup, part ORDER BY odate DESC ) AS rn FROM base WHERE version = 'Quotes' ) x WHERE rn = 1 ), flagged AS ( SELECT r.*, CASE WHEN rn_recent_sale = 1 THEN 'most_recent_sale' END AS flag1, CASE WHEN rn_recent_quote = 1 THEN 'most_recent_quote' END AS flag2, CASE WHEN r.version = 'Actual' AND r.customer = s.customer AND r.partgroup = s.partgroup AND r.part = s.part AND r.odate = s.odate AND r.ordnum = s.ordnum THEN 'last_feature_match_sale' END AS flag3, CASE WHEN r.version = 'Quotes' AND r.customer = q.customer AND r.partgroup = q.partgroup AND r.part = q.part AND r.odate = q.odate AND r.quoten = q.quoten THEN 'last_feature_match_quote' END AS flag4 FROM ranked r LEFT JOIN last_feature_sale s ON r.version = 'Actual' AND r.customer = s.customer AND r.partgroup = s.partgroup AND r.part = s.part LEFT JOIN last_feature_quote q ON r.version = 'Quotes' AND r.customer = q.customer AND r.partgroup = q.partgroup AND r.part = q.part ) SELECT * FROM flagged WHERE customer LIKE 'ESBENSHADE%' AND partgroup = 'XNS0T1G3' AND flag3 = 'last_feature_match_sale' flags_aggregated AS ( SELECT customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten, JSON_QUERY( '[' + STRING_AGG(QUOTENAME(flag, '"'), ',') + ']' ) AS flags FROM ( SELECT customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten, flag FROM flagged CROSS APPLY (VALUES (flag1), (flag2), (flag3), (flag4)) AS f(flag) WHERE flag IS NOT NULL ) AS flags_expanded GROUP BY customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten ), all_rows_with_flags AS ( SELECT b.customer, b.partgroup, b.dataseg, b.version, b.part, b.qty, b.price, b.odate, b.ordnum, b.quoten, ISNULL(f.flags, JSON_QUERY('[]')) AS flags FROM base b LEFT JOIN flags_aggregated f ON b.customer = f.customer AND b.partgroup = f.partgroup AND b.dataseg = f.dataseg AND b.version = f.version AND b.part = f.part AND b.qty = f.qty AND b.price = f.price AND b.odate = f.odate AND b.ordnum = f.ordnum AND ISNULL(b.quoten, -1) = ISNULL(f.quoten, -1) ), json_rows AS ( SELECT customer, partgroup, dataseg, CONCAT( '"', dataseg, '":', ( SELECT version, part, qty, price, odate, ordnum, quoten, flags FROM all_rows_with_flags sub WHERE sub.customer = main.customer AND sub.partgroup = main.partgroup AND sub.dataseg = main.dataseg FOR JSON PATH ) ) AS part_json FROM all_rows_with_flags main GROUP BY customer, partgroup, dataseg ), onerow AS ( SELECT customer, partgroup, CONCAT('{', STRING_AGG(part_json, ','), '}') AS part_stats FROM json_rows GROUP BY customer, partgroup ) INSERT INTO pricing.lastprice SELECT * FROM onerow; CREATE UNIQUE INDEX lastprice_cust_partgroup ON pricing.lastprice(customer, partgroup);