price_api/new_targets/make_hist.ms.sql

143 lines
3.1 KiB
SQL

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 pricing.lastprice FROM onerow
CREATE UNIQUE INDEX lastprice_cust_mold ON pricing.lastprice(customer, mold);
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 pricing.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'
AND o.ordnum = 935360
WITH exploded AS (
SELECT
lp.customer,
lp.mold,
p.[key] AS part_key,
j.qty,
j.price,
j.odate,
j.ordnum,
j.quoten,
CASE WHEN p.[key] = o.part COLLATE Latin1_General_BIN2 THEN 1 ELSE 0 END AS is_exact_match,
ROW_NUMBER() OVER (PARTITION BY lp.customer, lp.mold ORDER BY j.odate DESC) AS rn_most_recent
FROM rlarp.osm_stack o
LEFT JOIN pricing.lastprice lp ON lp.customer = o.customer AND lp.mold = o.mold
CROSS APPLY OPENJSON(lp.part_stats) AS p
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'
AND o.ordnum = 935360
),
tagged AS (
SELECT
part_key,
qty,
price,
odate,
ordnum,
quoten,
IIF(is_exact_match = 1, 1, NULL) AS is_exact_match,
IIF(rn_most_recent = 1, 1, NULL) AS is_most_recent
FROM exploded
)
--SELECT * FROM taggeg
SELECT (
SELECT
part_key AS [key],
qty,
price,
odate,
ordnum,
quoten,
is_exact_match,
is_most_recent
FROM tagged
FOR JSON PATH, INCLUDE_NULL_VALUES
) AS updated_json_array;