price_api/new_targets/scripts/make_hist.ms.sql

60 lines
1.4 KiB
SQL

--------------------------------------------------------------------------------
-- Step 1: Rebuild last price history at sales matrix refresh time
--------------------------------------------------------------------------------
DELETE FROM pricing.lastprice;
WITH srt AS (
SELECT
customer,
mold,
part,
version,
qty,
ROUND(sales_usd / qty, 5) AS price,
odate,
oseas,
ordnum,
quoten,
ROW_NUMBER() OVER (
PARTITION BY customer, mold, part, version
ORDER BY odate DESC
) AS rn
FROM rlarp.osm_stack
WHERE
--quotes can't be integrated until we have datasegment or correct part code
version IN ('Actual'/*,'Quotes'*/) 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,
version,
CONCAT(
'"', part, '":',
(
SELECT version, 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
)
INSERT INTO pricing.lastprice SELECT * FROM onerow;
--CREATE UNIQUE INDEX lastprice_cust_mold ON pricing.lastprice(customer, mold);