price_api/new_targets/scripts/matrix_apply.ms.sql

91 lines
2.0 KiB
SQL

-- SELECT count(*) FROM rlarp.osm_stack o INNER JOIN #lastprice l ON
-- l.customer = o.customer AND o.mold = l.mold
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;