initial work on matrix mssql
This commit is contained in:
parent
6e82e328eb
commit
91ccf40ac2
222
new_targets/scripts/matrix_guidance.ms.sql
Normal file
222
new_targets/scripts/matrix_guidance.ms.sql
Normal file
@ -0,0 +1,222 @@
|
||||
CREATE OR ALTER PROCEDURE pricing.batch_price_stack
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 1: Seed temp table from rlarp.osm_stack
|
||||
--------------------------------------------------------------------------------
|
||||
SELECT
|
||||
bill,
|
||||
ship,
|
||||
part,
|
||||
stlc,
|
||||
v1ds,
|
||||
vol,
|
||||
NULL AS chan,
|
||||
NULL AS cust,
|
||||
NULL AS tier,
|
||||
NULL AS pltq,
|
||||
NULL AS plevel,
|
||||
NULL AS hist,
|
||||
NULL AS last_price,
|
||||
NULL AS last_date,
|
||||
NULL AS last_order,
|
||||
NULL AS last_quote,
|
||||
NULL AS tprice,
|
||||
NULL AS guidance_price,
|
||||
NULL AS guidance_reason,
|
||||
'{}' AS expl,
|
||||
NULL AS list_price,
|
||||
NULL AS list_code
|
||||
INTO #queue
|
||||
FROM rlarp.osm_stack;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 2: Enrich
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE q
|
||||
SET
|
||||
chan =
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN 'WHS'
|
||||
ELSE 'DRP'
|
||||
END
|
||||
ELSE 'DIR'
|
||||
END,
|
||||
tier =
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIR' THEN bc.tier
|
||||
ELSE ISNULL(sc.tier, bc.tier)
|
||||
END,
|
||||
cust =
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN bc.dba
|
||||
ELSE sc.dba
|
||||
END
|
||||
ELSE q.bill
|
||||
END,
|
||||
pltq = i.mpck,
|
||||
plevel =
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN sc.plevel
|
||||
ELSE bc.plevel
|
||||
END
|
||||
ELSE bc.plevel
|
||||
END
|
||||
FROM #queue q
|
||||
LEFT JOIN rlarp.cust bc ON bc.code = q.bill
|
||||
LEFT JOIN rlarp.cust sc ON sc.code = q.ship
|
||||
LEFT JOIN CMSInterfaceIn.[CMS.CUSLG].itemm i ON i.item = q.part;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 3: Apply target price and embed JSON
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE q
|
||||
SET
|
||||
tprice = tp.price,
|
||||
expl = (
|
||||
SELECT
|
||||
'target price' AS [source],
|
||||
tp.price AS [target_price],
|
||||
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
|
||||
CAST(ROUND(q.vol / NULLIF(q.pltq, 0), 5) AS NUMERIC(20,5)) AS [exact_pallets],
|
||||
CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), '∞')) AS [volume range],
|
||||
q.cust AS [customer],
|
||||
q.chan AS [channel],
|
||||
TRIM(q.tier) AS [tier],
|
||||
JSON_QUERY(tp.math) AS [target math]
|
||||
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
||||
)
|
||||
FROM #queue q
|
||||
INNER JOIN pricing.target_prices tp ON
|
||||
q.stlc = tp.stlc
|
||||
AND q.v1ds = tp.ds
|
||||
AND q.chan = tp.chan
|
||||
AND q.tier = tp.tier
|
||||
AND FLOOR(q.vol / NULLIF(q.pltq, 0)) >= tp.lower_bound
|
||||
AND (
|
||||
tp.upper_bound IS NULL OR FLOOR(q.vol / NULLIF(q.pltq, 0)) < tp.upper_bound
|
||||
);
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 4: Pull last sale data
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE q
|
||||
SET
|
||||
hist = JSON_MODIFY('{}', '$.full_history', JSON_QUERY(lp.part_stats)),
|
||||
last_price = j.price,
|
||||
last_date = j.odate,
|
||||
last_order = j.ordnum,
|
||||
last_quote = j.quoten,
|
||||
expl = JSON_MODIFY(
|
||||
JSON_MODIFY(
|
||||
JSON_MODIFY(
|
||||
JSON_MODIFY(
|
||||
ISNULL(q.expl, '{}'),
|
||||
'$.last_price', j.price
|
||||
),
|
||||
'$.last_date', CONVERT(NVARCHAR(10), j.odate, 23)
|
||||
),
|
||||
'$.last_order', j.ordnum
|
||||
),
|
||||
'$.last_quote', j.quoten
|
||||
)
|
||||
FROM #queue q
|
||||
JOIN pricing.lastprice lp
|
||||
ON lp.customer = q.cust
|
||||
AND lp.mold = SUBSTRING(q.part, 1, 8)
|
||||
OUTER APPLY (
|
||||
SELECT TOP 1 *
|
||||
FROM OPENJSON(lp.part_stats) AS p
|
||||
OUTER APPLY OPENJSON(p.value)
|
||||
WITH (
|
||||
qty NUMERIC(20,5),
|
||||
price NUMERIC(20,5),
|
||||
odate DATE,
|
||||
ordnum INT,
|
||||
quoten INT
|
||||
) AS j
|
||||
WHERE p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = q.part
|
||||
ORDER BY j.odate DESC
|
||||
) AS j;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 5: Add list price info
|
||||
--------------------------------------------------------------------------------
|
||||
WITH ranked_prices AS (
|
||||
SELECT
|
||||
q.bill, q.ship, q.part, q.stlc, q.v1ds, q.vol,
|
||||
CAST(p.price AS NUMERIC(20,5)) AS price,
|
||||
p.jcplcd,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY q.bill, q.ship, q.part, q.stlc, q.v1ds, q.vol
|
||||
ORDER BY p.price ASC
|
||||
) AS rn
|
||||
FROM #queue q
|
||||
INNER JOIN CMSInterfaceIn."CMS.CUSLG".IPRCBHC i
|
||||
ON TRIM(i.jbplvl) = TRIM(q.plevel)
|
||||
AND CAST(GETDATE() AS DATE) BETWEEN i.jbfdat AND i.jbtdat
|
||||
INNER JOIN pricing.pricelist_ranged p
|
||||
ON p.jcplcd = TRIM(i.jbplcd)
|
||||
AND p.jcpart = q.part
|
||||
AND q.vol >= p.vb_from
|
||||
AND (p.vb_to IS NULL OR q.vol < p.vb_to)
|
||||
)
|
||||
UPDATE q
|
||||
SET
|
||||
list_price = rp.price,
|
||||
list_code = rp.jcplcd,
|
||||
expl = JSON_MODIFY(
|
||||
JSON_MODIFY(
|
||||
ISNULL(q.expl, '{}'),
|
||||
'$.list_price', rp.price
|
||||
),
|
||||
'$.list_code', rp.jcplcd
|
||||
)
|
||||
FROM #queue q
|
||||
JOIN ranked_prices rp
|
||||
ON q.bill = rp.bill
|
||||
AND q.ship = rp.ship
|
||||
AND q.part = rp.part
|
||||
AND q.stlc = rp.stlc
|
||||
AND q.v1ds = rp.v1ds
|
||||
AND q.vol = rp.vol
|
||||
AND rp.rn = 1;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 6: Apply guidance logic
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE q
|
||||
SET
|
||||
guidance_price = g.guidance_price,
|
||||
guidance_reason = g.guidance_reason,
|
||||
expl = JSON_MODIFY(
|
||||
JSON_MODIFY(
|
||||
ISNULL(q.expl, '{}'),
|
||||
'$.guidance_reason',
|
||||
g.guidance_reason
|
||||
),
|
||||
'$.guidance_price',
|
||||
g.guidance_price
|
||||
)
|
||||
FROM #queue q
|
||||
CROSS APPLY pricing.guidance_logic(
|
||||
CAST(JSON_VALUE(q.expl, '$.target_price') AS NUMERIC(20,5)),
|
||||
CAST(JSON_VALUE(q.expl, '$.last_price') AS NUMERIC(20,5)),
|
||||
CAST(JSON_VALUE(q.expl, '$.list_price') AS NUMERIC(20,5))
|
||||
) g;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Final output (to result table, or SELECT)
|
||||
--------------------------------------------------------------------------------
|
||||
SELECT * FROM #queue;
|
||||
|
||||
END;
|
||||
|
Loading…
Reference in New Issue
Block a user