118 lines
3.7 KiB
SQL
118 lines
3.7 KiB
SQL
CREATE OR ALTER FUNCTION pricing.single_price_call_fn (
|
|
@bill VARCHAR(100),
|
|
@ship VARCHAR(100),
|
|
@part VARCHAR(100),
|
|
@stlc VARCHAR(100),
|
|
@v1ds VARCHAR(100),
|
|
@vol NUMERIC(18,6)
|
|
)
|
|
RETURNS TABLE
|
|
AS
|
|
RETURN
|
|
(
|
|
WITH queue AS (
|
|
SELECT
|
|
@bill AS bill,
|
|
@ship AS ship,
|
|
@part AS part,
|
|
@stlc AS stlc,
|
|
@v1ds AS v1ds,
|
|
@vol AS vol
|
|
),
|
|
enriched AS (
|
|
SELECT
|
|
q.*,
|
|
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 AS chan,
|
|
CASE SUBSTRING(bc.cclass, 2, 3)
|
|
WHEN 'DIR' THEN bc.tier
|
|
ELSE ISNULL(sc.tier, bc.tier)
|
|
END AS tier,
|
|
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 AS cust,
|
|
i.mpck AS pltq
|
|
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
|
|
),
|
|
hist AS (
|
|
SELECT TOP 1
|
|
j.qty,
|
|
j.price,
|
|
j.odate,
|
|
j.ordnum,
|
|
j.quoten
|
|
FROM pricing.lastprice lp
|
|
OUTER APPLY 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
|
|
INNER JOIN enriched e ON
|
|
lp.customer = e.cust
|
|
AND lp.mold = SUBSTRING(e.part,1,8)
|
|
WHERE p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = e.part
|
|
ORDER BY j.odate DESC
|
|
),
|
|
hist_json AS (
|
|
SELECT
|
|
CAST(ROUND(h.price, 5) AS NVARCHAR(50)) AS last_price,
|
|
(
|
|
SELECT qty, price, odate, ordnum, quoten
|
|
FROM hist h
|
|
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
|
) AS hist
|
|
FROM hist h
|
|
),
|
|
final AS (
|
|
SELECT
|
|
e.part,
|
|
tp.price,
|
|
(
|
|
SELECT
|
|
'target price' AS [source],
|
|
tp.price AS [target_price],
|
|
CAST(hj.last_price AS NUMERIC(20,5)) AS [last_price],
|
|
FLOOR(e.vol / NULLIF(e.pltq, 0)) AS [calculated_pallets],
|
|
ROUND(e.vol / NULLIF(e.pltq, 0), 5) AS [exact_pallets],
|
|
CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), '∞')) AS [volume range],
|
|
e.cust AS [customer],
|
|
e.chan AS [channel],
|
|
e.tier AS [tier],
|
|
JSON_QUERY(tp.math) AS [target math],
|
|
JSON_QUERY(hj.hist) AS [price history]
|
|
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
|
) AS expl
|
|
FROM enriched e
|
|
INNER JOIN pricing.target_prices tp ON
|
|
e.stlc = tp.stlc
|
|
AND e.v1ds = tp.ds
|
|
AND e.chan = tp.chan
|
|
AND e.tier = tp.tier
|
|
AND FLOOR(e.vol / NULLIF(e.pltq, 0)) >= tp.lower_bound
|
|
AND (
|
|
tp.upper_bound IS NULL
|
|
OR FLOOR(e.vol / NULLIF(e.pltq, 0)) < tp.upper_bound
|
|
)
|
|
LEFT JOIN hist_json hj ON 1 = 1
|
|
)
|
|
SELECT price, expl FROM final
|
|
);
|