new targets
This commit is contained in:
parent
73608b3e33
commit
c58488e1b3
63
new_targets/price_queue_test.ms.sql
Normal file
63
new_targets/price_queue_test.ms.sql
Normal file
@ -0,0 +1,63 @@
|
||||
DELETE FROM pricing.price_queue;
|
||||
|
||||
INSERT INTO pricing.price_queue (bill, ship, part, stlc, v1ds, vol) SELECT 'GRIF0001','GRIF0001','XNS0T1G3G18B096','XNS0T1G3','v1:L..PLT..',9600;
|
||||
|
||||
SELECT * FROM pricing.price_queue
|
||||
|
||||
EXEC pricing.process_queue
|
||||
|
||||
|
||||
EXEC pricing.single_price_call
|
||||
@bill = 'GRIF0001',
|
||||
@ship = 'JRSG0001',
|
||||
@part = 'XNS0T1G3G18B096',
|
||||
@stlc = 'XNS0T1G3',
|
||||
@v1ds = 'v1:T..PLT..',
|
||||
@vol = 0;
|
||||
|
||||
EXEC pricing.single_price_call_nowrite
|
||||
@bill = 'GRIF0001',
|
||||
@ship = 'JRSG0001',
|
||||
@part = 'XNS0T1G3G18B096',
|
||||
@stlc = 'XNS0T1G3',
|
||||
@v1ds = 'v1:T..PLT..',
|
||||
@vol = 19200;
|
||||
|
||||
SELECT
|
||||
price, expl
|
||||
FROM pricing.fn_single_price_call(
|
||||
'GRIF0001',
|
||||
'JRSG0001',
|
||||
'XNS0T1G3G18B096',
|
||||
'XNS0T1G3',
|
||||
'v1:T..PLT..',
|
||||
12500
|
||||
) f
|
||||
|
||||
SELECT
|
||||
price
|
||||
,expl
|
||||
,JSON_VALUE(expl, '$."tier"') AS tier
|
||||
,JSON_VALUE(expl, '$."customer"') AS cust
|
||||
,JSON_QUERY(expl, '$."target math"') AS math
|
||||
FROM pricing.fn_single_price_call(
|
||||
'GRIF0001',
|
||||
'JRSG0001',
|
||||
'XNS0T1G3G18B096',
|
||||
'XNS0T1G3',
|
||||
'v1:T..PLT..',
|
||||
12500
|
||||
);
|
||||
|
||||
SELECT * INTO #result FROM pricing.price_queue WHERE 0=1
|
||||
|
||||
INSERT INTO #result
|
||||
EXEC pricing.single_price_call_nowrite
|
||||
@bill = 'GRIF0001',
|
||||
@ship = 'JRSG0001',
|
||||
@part = 'XNS0T1G3G18B096',
|
||||
@stlc = 'XNS0T1G3',
|
||||
@v1ds = 'v1:T..PLT..',
|
||||
@vol = 19200;
|
||||
|
||||
SELECT * FROM #RESULT
|
87
new_targets/price_queue_test.pg.sql
Normal file
87
new_targets/price_queue_test.pg.sql
Normal file
@ -0,0 +1,87 @@
|
||||
-- CREATE TABLE IF NOT EXISTS pricequote.price_queue (
|
||||
-- id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY
|
||||
-- ,bill TEXT
|
||||
-- ,ship TEXT
|
||||
-- ,part TEXT
|
||||
-- ,stlc TEXT
|
||||
-- ,v1ds TEXT
|
||||
-- ,vol NUMERIC
|
||||
-- ,chan TEXT
|
||||
-- ,tier TEXT
|
||||
-- ,pltq NUMERIC
|
||||
-- ,price NUMERIC
|
||||
-- ,expl JSONB
|
||||
-- );
|
||||
|
||||
DELETE FROM pricequote.price_queue;
|
||||
|
||||
INSERT INTO pricequote.price_queue (bill, ship, part, stlc, v1ds, vol) SELECT 'GRIF0001','GRIF0001','XNS0T1G3G18B096','XNS0T1G3','v1:L..PLT..',9600;
|
||||
|
||||
SELECT * FROM pricequote.process_queue()
|
||||
|
||||
-- --------------------------------------------------------------------------------
|
||||
-- ---------------------set channel, tier, & pallet quantitiy----------------------
|
||||
-- --------------------------------------------------------------------------------
|
||||
-- UPDATE
|
||||
-- pricequote.price_queue s
|
||||
-- SET
|
||||
-- chan = cr.chan,
|
||||
-- tier = cr.tier,
|
||||
-- pltq = cr.mpck
|
||||
-- FROM (
|
||||
-- SELECT
|
||||
-- q.bill
|
||||
-- ,q.ship
|
||||
-- ,q.part
|
||||
-- ,i.mpck
|
||||
-- ,CASE SUBSTRING(bc.cclass,2,3)
|
||||
-- --if the bill to class is ditsributor, then it's either warehouse or drop
|
||||
-- WHEN 'DIS' THEN
|
||||
-- --if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse
|
||||
-- CASE SUBSTRING(sc.cclass,2,3)
|
||||
-- WHEN 'DIS' THEN 'WHS'
|
||||
-- ELSE 'DRP'
|
||||
-- END
|
||||
-- --CASE WHEN RTRIM(SUBSTR(LTRIM(SC.BVADR7)||SC.BVNAME,1,30)) = RTRIM(SUBSTR(LTRIM(BC.BVADR7)||BC.BVNAME,1,30)) THEN 'DIS' ELSE 'DRP' END
|
||||
-- --everything else does not involve a distributor and is considered direct
|
||||
-- ELSE 'DIR'
|
||||
-- END AS chan
|
||||
-- ,CASE substring(bc.cclass,2,3)
|
||||
-- WHEN 'DIR' THEN bc.tier
|
||||
-- -------------some orders do not have a ship-to---------------
|
||||
-- ELSE COALESCE(sc.tier,bc.tier)
|
||||
-- END AS tier
|
||||
-- FROM
|
||||
-- pricequote.price_queue q
|
||||
-- LEFT OUTER JOIN rlarp.cust bc ON
|
||||
-- bc.code = q.bill
|
||||
-- LEFT OUTER JOIN rlarp.cust sc ON
|
||||
-- sc.code = q.ship
|
||||
-- LEFT OUTER JOIN "CMS.CUSLG".itemm i ON
|
||||
-- i.item = q.part
|
||||
-- ) cr
|
||||
-- WHERE
|
||||
-- cr.bill = s.bill
|
||||
-- AND COALESCE(cr.ship, '') = COALESCE(s.ship, '');
|
||||
--
|
||||
-- UPDATE
|
||||
-- pricequote.price_queue q
|
||||
-- SET
|
||||
-- price = tp.price
|
||||
-- ,expl = jsonb_build_object(
|
||||
-- 'source', 'target price',
|
||||
-- 'calculated_pallets', FLOOR(q.vol / NULLIF(q.pltq, 0))::INT,
|
||||
-- 'exact_pallets', ROUND(q.vol / NULLIF(q.pltq, 0),5),
|
||||
-- 'volume range',tp.vol
|
||||
-- )
|
||||
-- FROM
|
||||
-- pricequote.target_prices tp
|
||||
-- WHERE
|
||||
-- q.stlc = tp.stlc
|
||||
-- AND q.v1ds = tp.ds
|
||||
-- AND q.chan = tp.chan
|
||||
-- AND q.tier = tp.tier
|
||||
-- AND tp.vol @> FLOOR(q.vol/q.pltq)::INT;
|
||||
--
|
||||
-- SELECT * FROM pricequote.price_queue
|
||||
|
164
new_targets/procs/build_pricing_path.pg.sql
Normal file
164
new_targets/procs/build_pricing_path.pg.sql
Normal file
@ -0,0 +1,164 @@
|
||||
DROP FUNCTION pricequote.build_pricing_path;
|
||||
|
||||
CREATE OR REPLACE FUNCTION pricequote.build_pricing_path(
|
||||
_json JSONB
|
||||
)
|
||||
RETURNS TABLE (
|
||||
stlc TEXT
|
||||
,seq BIGINT
|
||||
,srtcode TEXT
|
||||
,ds TEXT
|
||||
,chan TEXT
|
||||
,tier TEXT
|
||||
,vol INT4RANGE
|
||||
,func TEXT
|
||||
,val NUMERIC
|
||||
,price NUMERIC
|
||||
,math TEXT[]
|
||||
,lastflag BOOLEAN
|
||||
)
|
||||
LANGUAGE plpgsql AS
|
||||
$$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
|
||||
WITH RECURSIVE
|
||||
-- 1️⃣ Parse JSONB into rows of (entity, attr, val)
|
||||
parsed AS (
|
||||
SELECT
|
||||
e.entity,
|
||||
COALESCE(e.attr, '') AS attr,
|
||||
e.val,
|
||||
e.func
|
||||
FROM jsonb_to_recordset(_json)
|
||||
AS e(entity TEXT, attr TEXT, val NUMERIC, func TEXT)
|
||||
),
|
||||
-- 2️⃣ Attach sequence & func from master option_sequence table
|
||||
sequenced AS (
|
||||
SELECT
|
||||
p.entity,
|
||||
p.attr,
|
||||
p.val,
|
||||
p.func,
|
||||
s.DOMAIN,
|
||||
DENSE_RANK() OVER (ORDER BY s.seq) AS seq,
|
||||
ROW_NUMBER() OVER (PARTITION BY p.entity ORDER BY COALESCE(p.val,0) ASC) srt
|
||||
FROM parsed p
|
||||
JOIN pricequote.option_sequence s
|
||||
ON p.entity = s.entity
|
||||
)
|
||||
--select * from sequenced ORDER BY seq, srt
|
||||
-- 3️⃣ Recursively accumulate pricing path
|
||||
,combos AS (
|
||||
-- 🚀 Base case: first in sequence
|
||||
SELECT
|
||||
s.entity,
|
||||
s.attr,
|
||||
s.seq,
|
||||
to_char(s.srt,'FM000') srtcode,
|
||||
'' ds,
|
||||
'' chan,
|
||||
'' tier,
|
||||
null::TEXT vol,
|
||||
s.func,
|
||||
s.val,
|
||||
s.val agg,
|
||||
-- jsonb_build_array(jsonb_build_object('entity',s.entity,'attr',s.attr,'function',s.func, 'val',s.val,'seq',s.seq)) math
|
||||
ARRAY[
|
||||
CASE
|
||||
WHEN s.func = 'Price' THEN
|
||||
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' + ' || LPAD(to_char(s.val, 'FM9999999990.00000'), 10, ' ')
|
||||
WHEN s.func = 'Factor' THEN
|
||||
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' x ' || LPAD(to_char(s.val, 'FM9999999990.00000'), 10, ' ')
|
||||
ELSE
|
||||
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' ' || LPAD(to_char(s.val, 'FM9999999990.00000'), 10, ' ')
|
||||
END
|
||||
] math
|
||||
FROM
|
||||
sequenced s
|
||||
WHERE
|
||||
s.seq = (SELECT MIN(x.seq) FROM sequenced x)
|
||||
UNION ALL
|
||||
-- 🔁 Recursive step: process next in sequence
|
||||
SELECT
|
||||
c.entity,
|
||||
c.attr,
|
||||
o.seq,
|
||||
c.srtcode || '.' || to_char(o.srt,'FM000'),
|
||||
c.ds || CASE WHEN o.DOMAIN = 'Product' THEN '.' || o.attr ELSE '' END ds,
|
||||
CASE WHEN o.DOMAIN = 'Channel' THEN o.attr ELSE c.chan END chan,
|
||||
CASE WHEN o.DOMAIN = 'Tier' THEN o.attr ELSE c.tier END tier,
|
||||
CASE WHEN o.DOMAIN = 'Volume' THEN o.attr ELSE c.vol END vol,
|
||||
o.func,
|
||||
o.val,
|
||||
CASE o.func WHEN 'Price' THEN c.agg + o.val WHEN 'Factor' THEN c.agg * o.val END agg,
|
||||
-- c.math || jsonb_build_array(jsonb_build_object('entity',o.entity,'attr',o.attr,'function',o.func, 'val',o.val,'seq',o.seq)) math,
|
||||
CASE WHEN (o.func = 'Price' AND o.val <> 0) OR (o.func = 'Factor' AND o.val <> 1) THEN
|
||||
c.math ||
|
||||
ARRAY[
|
||||
CASE
|
||||
WHEN o.func = 'Price' THEN
|
||||
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' + ' || LPAD(to_char(o.val, 'FM9999999990.00000'), 10, ' ')
|
||||
WHEN o.func = 'Factor' THEN
|
||||
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' x ' || LPAD(to_char(o.val, 'FM9999999990.00000'), 10, ' ')
|
||||
ELSE
|
||||
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' ' || LPAD(to_char(o.val, 'FM9999999990.00000'), 10, ' ')
|
||||
END
|
||||
]
|
||||
ELSE
|
||||
c.math
|
||||
END math
|
||||
FROM
|
||||
combos c
|
||||
JOIN sequenced o ON
|
||||
o.seq = c.seq + 1
|
||||
)
|
||||
SELECT
|
||||
-- c.entity
|
||||
c.attr
|
||||
,c.seq
|
||||
,c.srtcode
|
||||
,'v1:'||SUBSTRING(c.ds,2,100) ds
|
||||
,c.chan
|
||||
,c.tier
|
||||
-- ,c.vol
|
||||
,CASE
|
||||
WHEN c.vol ~ '^[0-9]+-[0-9]+$' THEN
|
||||
int4range(
|
||||
split_part(c.vol, '-', 1)::int,
|
||||
split_part(c.vol, '-', 2)::int,
|
||||
'[)'
|
||||
)
|
||||
WHEN c.vol ~ '^[0-9]+$' THEN
|
||||
int4range(
|
||||
c.vol::int,
|
||||
NULL,
|
||||
'[)'
|
||||
)
|
||||
ELSE NULL
|
||||
END AS vol
|
||||
,c.func
|
||||
,c.val
|
||||
,c.agg
|
||||
,c.math
|
||||
,c.seq = (SELECT max(x.seq) FROM sequenced x) lastflag
|
||||
FROM
|
||||
combos c /*WHERE seq = (SELECT max(seq) FROM sequenced)*/
|
||||
ORDER BY
|
||||
c.srtcode ASC;
|
||||
|
||||
END;
|
||||
$$;
|
||||
|
||||
/*
|
||||
Anchor:EU170S50 + 0.08
|
||||
Color Tier:P x 1.30
|
||||
Branding: + 0.00
|
||||
Packaging:SLV + 0.00
|
||||
Suffix:PCR x 1.00
|
||||
Accessories: + 0.00
|
||||
Channel:WHS + 0.00
|
||||
Volume:8 x 1.00
|
||||
-----------------------
|
||||
0.104
|
||||
*/
|
104
new_targets/procs/get_option_costs_priceg.pg.sql
Normal file
104
new_targets/procs/get_option_costs_priceg.pg.sql
Normal file
@ -0,0 +1,104 @@
|
||||
DROP FUNCTION IF EXISTS rlarp.get_option_costs_priceg;
|
||||
CREATE FUNCTION rlarp.get_option_costs_priceg(_priceg text, _majg text)
|
||||
RETURNS TABLE (
|
||||
stlc text
|
||||
,coltier text
|
||||
,branding text
|
||||
,accs_ps text
|
||||
,acc_list text
|
||||
,suffix text
|
||||
,uomp text
|
||||
,avgsc numeric
|
||||
,avgfc numeric
|
||||
,weight numeric
|
||||
,target numeric
|
||||
,futmargin numeric
|
||||
)
|
||||
LANGUAGE plpgsql AS
|
||||
$function$
|
||||
|
||||
BEGIN
|
||||
|
||||
RETURN QUERY
|
||||
WITH
|
||||
sel AS (
|
||||
SELECT
|
||||
i.stlc
|
||||
,i.coltier
|
||||
,i.branding
|
||||
--,accs
|
||||
,i.accs_ps
|
||||
,i.acc_list
|
||||
,i.suffix
|
||||
--,COALESCE(accs_ps,accs) accs_c
|
||||
--,jsonb_agg(DISTINCT r.aomult) cavitation
|
||||
--,jsonb_agg(DISTINCT r.aoctme) cyclet
|
||||
--,jsonb_arr_aggcd(mino) min_ord
|
||||
,i.uomp
|
||||
--,jsonb_agg(DISTINCT aplnt) aplnt
|
||||
--,jsonb_agg(DISTINCT colc) colc
|
||||
--,jsonb_agg(DISTINCT substring(item,12,case when branding = '' THEN 7 ELSE 4 end)) items
|
||||
--,jsonb_agg(DISTINCT majg) majgs
|
||||
--,jsonb_agg(DISTINCT assc) accs
|
||||
,round(avg(curstdus),5) avgsc
|
||||
,round(avg(futstdus),5) avgfc
|
||||
,round(avg(nwht),5) avgwt
|
||||
,i.v1ds
|
||||
FROM
|
||||
"CMS.CUSLG".itemm i
|
||||
WHERE
|
||||
true
|
||||
--stlc ~ 'TWA10200'
|
||||
--AND branding = ''
|
||||
AND aplnt <> 'I'
|
||||
AND COALESCE(i.uomp,'') <> ''
|
||||
--AND branding = ''
|
||||
GROUP BY
|
||||
i.stlc
|
||||
,i.coltier
|
||||
,i.uomp
|
||||
,i.branding
|
||||
,i.acc_list
|
||||
,i.accs_ps
|
||||
,i.suffix
|
||||
,i.v1ds
|
||||
ORDER BY
|
||||
i.stlc ASC
|
||||
)
|
||||
SELECT
|
||||
sel.stlc
|
||||
,sel.coltier
|
||||
,sel.branding
|
||||
,sel.accs_ps
|
||||
,sel.acc_list
|
||||
,sel.suffix
|
||||
,sel.uomp
|
||||
,sel.avgsc
|
||||
,sel.avgfc
|
||||
,sel.avgwt
|
||||
,t.price
|
||||
,round(CASE WHEN coalesce(t.price,0) <> 0 THEN (t.price-COALESCE(sel.avgfc,0))/t.price ELSE 0 END,3) futmarg
|
||||
FROM
|
||||
sel
|
||||
LEFT OUTER JOIN pricequote.target_prices t ON
|
||||
sel.stlc = t.stlc
|
||||
AND sel.v1ds = t.ds
|
||||
AND t.chan = 'DIR'
|
||||
AND COALESCE(t.tier,'') IN ('1')
|
||||
AND 24 <@ t.vol
|
||||
-- LEFT OUTER JOIN pricequote.market_setavgprice t ON
|
||||
-- t.mold = sel.stlc
|
||||
-- AND t.data_segment = sel.v1ds
|
||||
-- AND t.season = 2025
|
||||
-- AND t.chan = 'DIRECT'
|
||||
-- AND t.country = 'ALL'
|
||||
-- AND t.geo = 'ALL'
|
||||
-- AND t.region = 'ALL'
|
||||
WHERE
|
||||
sel.stlc IN (SELECT DISTINCT m.stlc FROM rlarp.molds m WHERE m.priceg ~ _priceg AND m.majg ~ _majg);
|
||||
|
||||
END
|
||||
|
||||
$function$
|
||||
|
||||
|
194
new_targets/procs/get_options_merged.pg.sql
Normal file
194
new_targets/procs/get_options_merged.pg.sql
Normal file
@ -0,0 +1,194 @@
|
||||
DROP FUNCTION rlarp.get_options_merged;
|
||||
|
||||
CREATE OR REPLACE FUNCTION rlarp.get_options_merged(
|
||||
_priceg TEXT,
|
||||
_majg TEXT,
|
||||
existing_json JSONB
|
||||
)
|
||||
RETURNS TABLE (
|
||||
entity TEXT,
|
||||
attr TEXT,
|
||||
val NUMERIC,
|
||||
func TEXT
|
||||
)
|
||||
LANGUAGE plpgsql AS
|
||||
$$
|
||||
BEGIN
|
||||
|
||||
RETURN QUERY
|
||||
WITH
|
||||
|
||||
-- 1️⃣ Parse existing pricing from JSONB
|
||||
existing AS (
|
||||
SELECT
|
||||
e.entity,
|
||||
COALESCE(e.attr, '') AS attr,
|
||||
e.val,
|
||||
e.func
|
||||
FROM jsonb_to_recordset(existing_json)
|
||||
AS e(entity TEXT, attr TEXT, val NUMERIC, func TEXT)
|
||||
)
|
||||
,items AS (
|
||||
SELECT
|
||||
item
|
||||
FROM
|
||||
"CMS.CUSLG".itemm
|
||||
WHERE
|
||||
stlc IN (SELECT DISTINCT stlc FROM "CMS.CUSLG".itemm WHERE pricegroup ~ _priceg AND majg ~ _majg)
|
||||
AND aplnt <> 'I'
|
||||
)
|
||||
-- 2️⃣ Build raw stack without hard-coded func
|
||||
,stack AS (
|
||||
-- Anchor
|
||||
SELECT 'Anchor' AS entity, stlc AS attr, 0::numeric AS val
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (
|
||||
SELECT item
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (SELECT item FROM items)
|
||||
)
|
||||
GROUP BY stlc
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Color Tier
|
||||
SELECT 'Color Tier' AS entity, coltier AS attr, 1 AS val
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (
|
||||
SELECT item
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (SELECT item FROM items)
|
||||
)
|
||||
GROUP BY coltier
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Branding
|
||||
SELECT 'Branding' AS entity, COALESCE(substring(branding,1,1), '') AS attr, 0 AS val
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (
|
||||
SELECT item
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (SELECT item FROM items)
|
||||
)
|
||||
GROUP BY COALESCE(substring(branding,1,1), '')
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Packaging
|
||||
SELECT 'Packaging' AS entity, COALESCE(uomp, '') AS attr, 0 AS val
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (
|
||||
SELECT item
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (SELECT item FROM items)
|
||||
)
|
||||
GROUP BY COALESCE(uomp, '')
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Accessories
|
||||
SELECT 'Accessories' AS entity, COALESCE(accs_ps, '') AS attr, 0 AS val
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (
|
||||
SELECT item
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (SELECT item FROM items)
|
||||
)
|
||||
GROUP BY COALESCE(accs_ps, '')
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Suffix
|
||||
SELECT 'Suffix' AS entity, COALESCE(suffix, '') AS attr, 1 AS val
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (
|
||||
SELECT item
|
||||
FROM "CMS.CUSLG".itemm
|
||||
WHERE item IN (SELECT item FROM items)
|
||||
)
|
||||
GROUP BY COALESCE(suffix, '')
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Channel
|
||||
SELECT 'Channel' AS entity, x.chan AS attr, 0 AS val
|
||||
FROM (VALUES ('DIR'), ('DRP'), ('WHS')) AS x(chan)
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Customer Tier
|
||||
SELECT 'Tier' AS entity, x.tier AS attr, 0 AS val
|
||||
FROM (VALUES ('1'), ('2'), ('3')) AS x(tier)
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Volume
|
||||
SELECT 'Volume' AS entity, x.chan AS attr, 0 AS val
|
||||
FROM (VALUES ('0-1'),('1-8'),('8-24'),('24')) AS x(chan)
|
||||
),
|
||||
|
||||
-- 3️⃣ Attach pricing func and sequence from option_sequence
|
||||
stack_with_meta AS (
|
||||
SELECT
|
||||
s.entity,
|
||||
COALESCE(s.attr, '') AS attr,
|
||||
s.val,
|
||||
os.func,
|
||||
os.seq
|
||||
FROM stack s
|
||||
LEFT JOIN pricequote.option_sequence os
|
||||
ON s.entity = os.entity
|
||||
),
|
||||
|
||||
-- 4️⃣ Merge: master rows with overrides
|
||||
overridden AS (
|
||||
SELECT
|
||||
s.entity,
|
||||
s.attr,
|
||||
COALESCE(e.val, s.val) AS val,
|
||||
s.func,
|
||||
s.seq
|
||||
FROM stack_with_meta s
|
||||
LEFT JOIN existing e
|
||||
ON s.entity = e.entity
|
||||
AND COALESCE(s.attr, '') = COALESCE(e.attr, '')
|
||||
AND s.func = e.func
|
||||
),
|
||||
|
||||
-- 5️⃣ Extras in saved JSON but not in master
|
||||
extras AS (
|
||||
SELECT
|
||||
e.entity,
|
||||
COALESCE(e.attr, '') AS attr,
|
||||
e.val,
|
||||
e.func,
|
||||
os.seq
|
||||
FROM existing e
|
||||
LEFT JOIN stack_with_meta s
|
||||
ON e.entity = s.entity
|
||||
AND COALESCE(e.attr, '') = COALESCE(s.attr, '')
|
||||
AND e.func = s.func
|
||||
LEFT JOIN pricequote.option_sequence os
|
||||
ON e.entity = os.entity
|
||||
WHERE s.entity IS NULL
|
||||
),
|
||||
|
||||
-- 6️⃣ Combine both sources
|
||||
combined AS (
|
||||
SELECT o.entity, o.attr, o.val, o.func, o.seq FROM overridden o
|
||||
UNION ALL
|
||||
SELECT e.entity, e.attr, e.val, e.func, e.seq FROM extras e
|
||||
)
|
||||
|
||||
-- 7️⃣ Return ordered by sequence
|
||||
SELECT
|
||||
combined.entity,
|
||||
combined.attr,
|
||||
combined.val,
|
||||
combined.func
|
||||
FROM combined
|
||||
ORDER BY combined.seq NULLS LAST, combined.entity, combined.attr;
|
||||
|
||||
END;
|
||||
$$;
|
42
new_targets/procs/load_target_price.pg.sql
Normal file
42
new_targets/procs/load_target_price.pg.sql
Normal file
@ -0,0 +1,42 @@
|
||||
CREATE OR REPLACE PROCEDURE pricequote.load_target_prices(input_json JSONB)
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
-- 1️⃣ Materialize the function output once
|
||||
CREATE TEMP TABLE temp_new_data ON COMMIT DROP AS
|
||||
SELECT
|
||||
stlc, ds, chan, tier, vol, price, math
|
||||
FROM
|
||||
pricequote.build_pricing_path(input_json)
|
||||
WHERE
|
||||
lastflag;
|
||||
|
||||
-- 2️⃣ Delete matching old rows
|
||||
DELETE FROM pricequote.target_prices t
|
||||
USING (
|
||||
SELECT DISTINCT stlc FROM temp_new_data
|
||||
) to_delete
|
||||
WHERE t.stlc = to_delete.stlc;
|
||||
|
||||
-- 3️⃣ Insert new rows
|
||||
INSERT INTO pricequote.target_prices (stlc, ds, chan, tier, vol, price, math)
|
||||
SELECT stlc, ds, chan, tier, vol, price, math FROM temp_new_data;
|
||||
|
||||
END;
|
||||
$$;
|
||||
|
||||
/*
|
||||
SELECT
|
||||
stlc,
|
||||
ds,
|
||||
chan,
|
||||
tier,
|
||||
vol,
|
||||
price,
|
||||
-- array_to_string(math, E'\n') AS math_text
|
||||
jsonb_build_object('target math',to_jsonb(math)) AS math_text
|
||||
FROM
|
||||
pricequote.build_pricing_path('[{"entity":"Anchor","attr":"JNS0T1G3","val":"0.08","func":"Price"},{"entity":"Anchor","attr":"XNS0T1G3","val":"0.08","func":"Price"},{"entity":"Anchor","attr":"XRD16002","val":"0.085","func":"Price"},{"entity":"Anchor","attr":"EU170S50","val":"0.085","func":"Price"},{"entity":"Anchor","attr":"EU170T50","val":"0.095","func":"Price"},{"entity":"Anchor","attr":"AZN06501","val":"0.12","func":"Price"},{"entity":"Anchor","attr":"1CP07010","val":"0.125","func":"Price"},{"entity":"Anchor","attr":"1CP06060","val":"0.13","func":"Price"},{"entity":"Anchor","attr":"AZA06500","val":"0.15","func":"Price"},{"entity":"Color Tier","attr":"B","val":1,"func":"Factor"},{"entity":"Color Tier","attr":"T","val":1.1,"func":"Factor"},{"entity":"Color Tier","attr":"L","val":1.1,"func":"Factor"},{"entity":"Color Tier","attr":"M","val":1.2,"func":"Factor"},{"entity":"Color Tier","attr":"P","val":1.3,"func":"Factor"},{"entity":"Color Tier","attr":"C","val":1.35,"func":"Factor"},{"entity":"Branding","val":"0","func":"Price"},{"entity":"Branding","attr":"L","val":"0.03","func":"Price"},{"entity":"Branding","attr":"P","val":"0.08","func":"Price"},{"entity":"Packaging","attr":"BDL","val":"0.002","func":"Price"},{"entity":"Packaging","attr":"CSE","val":"0.005","func":"Price"},{"entity":"Packaging","attr":"PC","val":"0.005","func":"Price"},{"entity":"Packaging","attr":"PLT","val":"0","func":"Price"},{"entity":"Packaging","attr":"SLV","val":"0.002","func":"Price"},{"entity":"Suffix","val":1,"func":"Factor"},{"entity":"Accessories","val":"0","func":"Price"},{"entity":"Channel","attr":"DIR","val":1,"func":"Factor"},{"entity":"Channel","attr":"DRP","val":1,"func":"Factor"},{"entity":"Channel","attr":"WHS","val":1.2,"func":"Factor"},{"entity":"Volume","attr":24,"val":1,"func":"Factor"},{"entity":"Volume","attr":"8-24","val":1.05,"func":"Factor"},{"entity":"Volume","attr":"1-8","val":1.1,"func":"Factor"},{"entity":"Volume","attr":"0-1","val":1.2,"func":"Factor"},{"entity":"Tier","attr":1,"val":1,"func":"Factor"},{"entity":"Tier","attr":2,"val":1.05,"func":"Factor"},{"entity":"Tier","attr":3,"val":1.07,"func":"Factor"}]'::jsonb)
|
||||
WHERE
|
||||
lastflag
|
||||
*/
|
109
new_targets/procs/process_queue.ms.sql
Normal file
109
new_targets/procs/process_queue.ms.sql
Normal file
@ -0,0 +1,109 @@
|
||||
CREATE OR ALTER PROCEDURE pricing.process_queue
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 1: Insert input row into real queue table
|
||||
--------------------------------------------------------------------------------
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 2: Enrich the row with chan, tier, cust, pltq
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE q
|
||||
SET
|
||||
q.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,
|
||||
q.tier =
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIR' THEN bc.tier
|
||||
ELSE ISNULL(sc.tier, bc.tier)
|
||||
END,
|
||||
q.cust =
|
||||
CASE SUBSTRING(bc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN
|
||||
CASE SUBSTRING(sc.cclass, 2, 3)
|
||||
WHEN 'DIS' THEN q.ship
|
||||
ELSE q.ship
|
||||
END
|
||||
ELSE q.bill
|
||||
END,
|
||||
q.pltq = i.mpck
|
||||
FROM
|
||||
pricing.price_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 pricing from target_prices
|
||||
--------------------------------------------------------------------------------
|
||||
|
||||
DECLARE @updated TABLE (
|
||||
id BIGINT,
|
||||
bill VARCHAR(100),
|
||||
ship VARCHAR(100),
|
||||
part VARCHAR(100),
|
||||
stlc VARCHAR(100),
|
||||
v1ds VARCHAR(100),
|
||||
vol NUMERIC(18,6),
|
||||
chan VARCHAR(50),
|
||||
cust VARCHAR(100),
|
||||
tier VARCHAR(50),
|
||||
pltq NUMERIC(18,6),
|
||||
price NUMERIC(18,6),
|
||||
expl NVARCHAR(MAX)
|
||||
);
|
||||
|
||||
UPDATE q
|
||||
SET
|
||||
q.price = tp.price,
|
||||
q.expl = (
|
||||
SELECT
|
||||
'target price' AS [source],
|
||||
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
|
||||
ROUND(q.vol / NULLIF(q.pltq, 0), 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],
|
||||
q.tier AS [tier],
|
||||
JSON_QUERY(tp.math) AS [target math] -- important if math is JSON
|
||||
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
||||
)
|
||||
OUTPUT
|
||||
inserted.id,
|
||||
inserted.bill,
|
||||
inserted.ship,
|
||||
inserted.part,
|
||||
inserted.stlc,
|
||||
inserted.v1ds,
|
||||
inserted.vol,
|
||||
inserted.chan,
|
||||
inserted.cust,
|
||||
inserted.tier,
|
||||
inserted.pltq,
|
||||
inserted.price,
|
||||
inserted.expl
|
||||
INTO @updated
|
||||
FROM pricing.price_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: Return just the enriched row
|
||||
--------------------------------------------------------------------------------
|
||||
SELECT * FROM @updated;
|
||||
END;
|
69
new_targets/procs/process_queue.pg.sql
Normal file
69
new_targets/procs/process_queue.pg.sql
Normal file
@ -0,0 +1,69 @@
|
||||
CREATE OR REPLACE FUNCTION pricequote.process_queue()
|
||||
RETURNS SETOF pricequote.price_queue
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 1: Set channel, tier, and pallet quantity
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE pricequote.price_queue s
|
||||
SET
|
||||
chan = cr.chan,
|
||||
tier = cr.tier,
|
||||
pltq = cr.mpck
|
||||
FROM (
|
||||
SELECT
|
||||
q.bill,
|
||||
q.ship,
|
||||
q.part,
|
||||
i.mpck,
|
||||
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 COALESCE(sc.tier, bc.tier)
|
||||
END AS tier
|
||||
FROM pricequote.price_queue q
|
||||
LEFT JOIN rlarp.cust bc ON bc.code = q.bill
|
||||
LEFT JOIN rlarp.cust sc ON sc.code = q.ship
|
||||
LEFT JOIN "CMS.CUSLG".itemm i ON i.item = q.part
|
||||
) cr
|
||||
WHERE
|
||||
cr.bill = s.bill AND
|
||||
COALESCE(cr.ship, '') = COALESCE(s.ship, '') AND
|
||||
cr.part = s.part;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 2: Set price and explanation from target_prices, return touched rows
|
||||
--------------------------------------------------------------------------------
|
||||
RETURN QUERY
|
||||
WITH updated AS (
|
||||
UPDATE pricequote.price_queue q
|
||||
SET
|
||||
price = tp.price,
|
||||
expl = jsonb_build_object(
|
||||
'source', 'target price',
|
||||
'calculated_pallets', FLOOR(q.vol / NULLIF(q.pltq, 0))::INT,
|
||||
'exact_pallets', ROUND(q.vol / NULLIF(q.pltq, 0), 5),
|
||||
'volume range', tp.vol
|
||||
)
|
||||
FROM pricequote.target_prices tp
|
||||
WHERE
|
||||
q.stlc = tp.stlc
|
||||
AND q.v1ds = tp.ds
|
||||
AND q.chan = tp.chan
|
||||
AND q.tier = tp.tier
|
||||
AND tp.vol @> FLOOR(q.vol / NULLIF(q.pltq, 0))::INT
|
||||
RETURNING q.*
|
||||
)
|
||||
SELECT * FROM updated;
|
||||
|
||||
END;
|
||||
$$;
|
87
new_targets/procs/single_price_call.ms.sql
Normal file
87
new_targets/procs/single_price_call.ms.sql
Normal file
@ -0,0 +1,87 @@
|
||||
CREATE OR ALTER PROCEDURE pricing.single_price_call
|
||||
@bill VARCHAR(100),
|
||||
@ship VARCHAR(100),
|
||||
@part VARCHAR(100),
|
||||
@stlc VARCHAR(100),
|
||||
@v1ds VARCHAR(100),
|
||||
@vol NUMERIC(18,6)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
DECLARE @id BIGINT;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 1: Insert input row into real queue table
|
||||
--------------------------------------------------------------------------------
|
||||
INSERT INTO pricing.price_queue (bill, ship, part, stlc, v1ds, vol)
|
||||
VALUES (@bill, @ship, @part, @stlc, @v1ds, @vol);
|
||||
|
||||
SET @id = SCOPE_IDENTITY(); -- Get the ID of the newly inserted row
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 2: Enrich the row with chan, tier, cust, pltq
|
||||
--------------------------------------------------------------------------------
|
||||
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 q.ship
|
||||
ELSE q.bill
|
||||
END,
|
||||
pltq = i.mpck
|
||||
FROM pricing.price_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
|
||||
WHERE q.id = @id;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 3: Apply pricing from target_prices
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE q
|
||||
SET
|
||||
price = tp.price,
|
||||
expl = (
|
||||
SELECT
|
||||
'target price' AS [source],
|
||||
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
|
||||
ROUND(q.vol / NULLIF(q.pltq, 0), 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],
|
||||
q.tier AS [tier],
|
||||
JSON_QUERY(tp.math) AS [target math] -- important if math is JSON
|
||||
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
|
||||
)
|
||||
FROM pricing.price_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
|
||||
)
|
||||
WHERE q.id = @id;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 4: Return just the enriched row
|
||||
--------------------------------------------------------------------------------
|
||||
SELECT * FROM pricing.price_queue WHERE id = @id;
|
||||
END;
|
116
new_targets/procs/single_price_call_func.ms.sql
Normal file
116
new_targets/procs/single_price_call_func.ms.sql
Normal file
@ -0,0 +1,116 @@
|
||||
CREATE OR ALTER FUNCTION pricing.fn_single_price_call (
|
||||
@bill VARCHAR(100),
|
||||
@ship VARCHAR(100),
|
||||
@part VARCHAR(100),
|
||||
@stlc VARCHAR(100),
|
||||
@v1ds VARCHAR(100),
|
||||
@vol NUMERIC(18,6)
|
||||
)
|
||||
RETURNS @result TABLE (
|
||||
bill VARCHAR(100),
|
||||
ship VARCHAR(100),
|
||||
part VARCHAR(100),
|
||||
stlc VARCHAR(100),
|
||||
v1ds VARCHAR(100),
|
||||
vol NUMERIC(18,6),
|
||||
cust VARCHAR(100),
|
||||
chan VARCHAR(50),
|
||||
tier VARCHAR(50),
|
||||
pltq NUMERIC(18,6),
|
||||
price NUMERIC(18,6),
|
||||
expl NVARCHAR(MAX)
|
||||
)
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE @queue TABLE (
|
||||
bill VARCHAR(100),
|
||||
ship VARCHAR(100),
|
||||
part VARCHAR(100),
|
||||
stlc VARCHAR(100),
|
||||
v1ds VARCHAR(100),
|
||||
vol NUMERIC(18,6),
|
||||
cust VARCHAR(100),
|
||||
chan VARCHAR(50),
|
||||
tier VARCHAR(50),
|
||||
pltq NUMERIC(18,6),
|
||||
price NUMERIC(18,6),
|
||||
expl NVARCHAR(MAX)
|
||||
);
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 1: Insert input row into real queue table
|
||||
--------------------------------------------------------------------------------
|
||||
INSERT INTO @queue (bill, ship, part, stlc, v1ds, vol)
|
||||
VALUES (@bill, @ship, @part, @stlc, @v1ds, @vol);
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 2: Enrich the row with chan, tier, cust, pltq
|
||||
--------------------------------------------------------------------------------
|
||||
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 q.ship
|
||||
ELSE q.ship
|
||||
END
|
||||
ELSE q.bill
|
||||
END,
|
||||
pltq = i.mpck
|
||||
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 pricing from target_prices
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE q
|
||||
SET
|
||||
price = tp.price,
|
||||
expl = (
|
||||
SELECT
|
||||
'target price' AS [source],
|
||||
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
|
||||
ROUND(q.vol / NULLIF(q.pltq, 0), 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],
|
||||
q.tier AS [tier],
|
||||
JSON_QUERY(tp.math) AS [target math] -- important if math is JSON
|
||||
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: Return just the enriched row
|
||||
--------------------------------------------------------------------------------
|
||||
INSERT INTO @result
|
||||
SELECT * FROM @queue;
|
||||
|
||||
RETURN;
|
||||
END;
|
101
new_targets/procs/single_price_call_nowrite.ms.sql
Normal file
101
new_targets/procs/single_price_call_nowrite.ms.sql
Normal file
@ -0,0 +1,101 @@
|
||||
CREATE OR ALTER PROCEDURE pricing.single_price_call_nowrite
|
||||
@bill VARCHAR(100),
|
||||
@ship VARCHAR(100),
|
||||
@part VARCHAR(100),
|
||||
@stlc VARCHAR(100),
|
||||
@v1ds VARCHAR(100),
|
||||
@vol NUMERIC(18,6)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- Declare table variable for the input row
|
||||
DECLARE @queue TABLE (
|
||||
bill VARCHAR(100),
|
||||
ship VARCHAR(100),
|
||||
part VARCHAR(100),
|
||||
stlc VARCHAR(100),
|
||||
v1ds VARCHAR(100),
|
||||
vol NUMERIC(18,6),
|
||||
chan VARCHAR(50),
|
||||
cust VARCHAR(100),
|
||||
tier VARCHAR(50),
|
||||
pltq NUMERIC(18,6),
|
||||
price NUMERIC(18,6),
|
||||
expl NVARCHAR(MAX)
|
||||
);
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 1: Insert input row into real queue table
|
||||
--------------------------------------------------------------------------------
|
||||
INSERT INTO @queue (bill, ship, part, stlc, v1ds, vol)
|
||||
VALUES (@bill, @ship, @part, @stlc, @v1ds, @vol);
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 2: Enrich the row with chan, tier, cust, pltq
|
||||
--------------------------------------------------------------------------------
|
||||
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 q.ship
|
||||
ELSE q.ship
|
||||
END
|
||||
ELSE q.bill
|
||||
END,
|
||||
pltq = i.mpck
|
||||
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 pricing from target_prices
|
||||
--------------------------------------------------------------------------------
|
||||
UPDATE q
|
||||
SET
|
||||
price = tp.price,
|
||||
expl = (
|
||||
SELECT
|
||||
'target price' AS [source],
|
||||
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
|
||||
ROUND(q.vol / NULLIF(q.pltq, 0), 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],
|
||||
q.tier AS [tier],
|
||||
JSON_QUERY(tp.math) AS [target math] -- important if math is JSON
|
||||
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: Return just the enriched row
|
||||
--------------------------------------------------------------------------------
|
||||
SELECT * FROM @queue;
|
||||
END;
|
17
new_targets/tables/price_queue.ms.sql
Normal file
17
new_targets/tables/price_queue.ms.sql
Normal file
@ -0,0 +1,17 @@
|
||||
DROP TABLE pricing.price_queue
|
||||
|
||||
CREATE TABLE pricing.price_queue (
|
||||
id BIGINT IDENTITY(1,1) PRIMARY KEY,
|
||||
bill VARCHAR(100),
|
||||
ship VARCHAR(100),
|
||||
part VARCHAR(100),
|
||||
stlc VARCHAR(100),
|
||||
v1ds VARCHAR(100),
|
||||
vol NUMERIC(18,6),
|
||||
chan VARCHAR(50),
|
||||
cust VARCHAR(100),
|
||||
tier VARCHAR(50),
|
||||
pltq NUMERIC(18,6),
|
||||
price NUMERIC(18,6),
|
||||
expl NVARCHAR(MAX) -- if storing JSON-like data
|
||||
);
|
16
new_targets/tables/price_queue.pg.sql
Normal file
16
new_targets/tables/price_queue.pg.sql
Normal file
@ -0,0 +1,16 @@
|
||||
CREATE TABLE IF NOT EXISTS pricequote.price_queue (
|
||||
id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY
|
||||
,bill TEXT
|
||||
,ship TEXT
|
||||
,part TEXT
|
||||
,stlc TEXT
|
||||
,v1ds TEXT
|
||||
,vol NUMERIC
|
||||
,chan TEXT
|
||||
,tier TEXT
|
||||
,pltq NUMERIC
|
||||
,price NUMERIC
|
||||
,expl JSONB
|
||||
);
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON pricequote.price_queue TO PUBLIC;
|
18
new_targets/tables/target_prices.ms.sql
Normal file
18
new_targets/tables/target_prices.ms.sql
Normal file
@ -0,0 +1,18 @@
|
||||
DROP TABLE pricing.target_prices;
|
||||
|
||||
CREATE TABLE pricing.target_prices (
|
||||
stlc nvarchar(8) NOT NULL,
|
||||
ds nvarchar(20) NOT NULL,
|
||||
chan nvarchar(3) NOT NULL,
|
||||
tier nvarchar(1) NOT NULL,
|
||||
vol nvarchar(20) NOT NULL,
|
||||
lower_bound int NOT NULL,
|
||||
upper_bound int NULL,
|
||||
price numeric(28,6) NOT NULL,
|
||||
math nvarchar(MAX) NULL
|
||||
);
|
||||
|
||||
ALTER TABLE pricing.target_prices
|
||||
ADD CONSTRAINT uq_target_prices_unique_combo
|
||||
UNIQUE (stlc, ds, chan, tier, vol, lower_bound);
|
||||
|
14
new_targets/tables/target_prices.pg.sql
Normal file
14
new_targets/tables/target_prices.pg.sql
Normal file
@ -0,0 +1,14 @@
|
||||
DROP TABLE pricequote.target_prices CASCADE;
|
||||
|
||||
CREATE TABLE pricequote.target_prices (
|
||||
stlc TEXT NOT NULL,
|
||||
ds TEXT NOT NULL,
|
||||
chan TEXT NOT NULL,
|
||||
tier TEXT NOT NULL,
|
||||
vol INT4RANGE NOT NULL,
|
||||
price NUMERIC,
|
||||
math TEXT[],
|
||||
PRIMARY KEY (stlc, ds, chan, tier, vol)
|
||||
);
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON pricequote.target_prices TO PUBLIC;
|
11
new_targets/tables/target_prices_view.pg.sql
Normal file
11
new_targets/tables/target_prices_view.pg.sql
Normal file
@ -0,0 +1,11 @@
|
||||
CREATE or REPLACE VIEW pricequote.target_prices_view AS
|
||||
SELECT
|
||||
stlc
|
||||
,ds
|
||||
,chan
|
||||
,tier
|
||||
,vol::text vol
|
||||
,price
|
||||
,to_jsonb(math)::text AS math
|
||||
FROM
|
||||
pricequote.target_prices;
|
23
new_targets/target_prices_copy.ms.sql
Normal file
23
new_targets/target_prices_copy.ms.sql
Normal file
@ -0,0 +1,23 @@
|
||||
DELETE FROM pricing.target_prices;
|
||||
|
||||
INSERT INTO
|
||||
pricing.target_prices
|
||||
SELECT
|
||||
stlc,
|
||||
ds,
|
||||
chan,
|
||||
tier,
|
||||
vol,
|
||||
-- Extract lower bound: text between '[' and ','
|
||||
TRY_CAST(SUBSTRING(vol, 2, CHARINDEX(',', vol) - 2) AS INT) AS lower_bound,
|
||||
-- Extract upper bound: text between ',' and ')'
|
||||
CASE
|
||||
WHEN RIGHT(vol, 2) = ',)' THEN NULL
|
||||
ELSE TRY_CAST(SUBSTRING(vol, CHARINDEX(',', vol) + 1, LEN(vol) - CHARINDEX(',', vol) - 1) AS INT)
|
||||
END AS upper_bound,
|
||||
price,
|
||||
math
|
||||
FROM
|
||||
usmidsap02.ubm.pricequote.target_prices_view;
|
||||
|
||||
--SELECT COUNT(*) FROM pricing.target_prices
|
55
new_targets/target_prices_unpack.ms.sql
Normal file
55
new_targets/target_prices_unpack.ms.sql
Normal file
@ -0,0 +1,55 @@
|
||||
--SELECT * INTO rlarp.target_prices FROM usmidsap02.ubm.pricequote.target_prices_view
|
||||
--DROP TABLE pricing.target_prices
|
||||
DELETE FROM pricing.target_prices
|
||||
|
||||
SELECT
|
||||
stlc,
|
||||
ds,
|
||||
chan,
|
||||
tier,
|
||||
vol,
|
||||
-- Extract lower bound: text between '[' and ','
|
||||
TRY_CAST(SUBSTRING(vol, 2, CHARINDEX(',', vol) - 2) AS INT) AS lower_bound,
|
||||
-- Extract upper bound: text between ',' and ')'
|
||||
CASE
|
||||
WHEN RIGHT(vol, 2) = ',)' THEN NULL
|
||||
ELSE TRY_CAST(SUBSTRING(vol, CHARINDEX(',', vol) + 1, LEN(vol) - CHARINDEX(',', vol) - 1) AS INT)
|
||||
END AS upper_bound,
|
||||
price,
|
||||
math
|
||||
INTO
|
||||
pricing.target_prices
|
||||
FROM
|
||||
usmidsap02.ubm.pricequote.target_prices_view;
|
||||
|
||||
INSERT INTO
|
||||
pricing.target_prices
|
||||
SELECT
|
||||
stlc,
|
||||
ds,
|
||||
chan,
|
||||
tier,
|
||||
vol,
|
||||
-- Extract lower bound: text between '[' and ','
|
||||
TRY_CAST(SUBSTRING(vol, 2, CHARINDEX(',', vol) - 2) AS INT) AS lower_bound,
|
||||
-- Extract upper bound: text between ',' and ')'
|
||||
CASE
|
||||
WHEN RIGHT(vol, 2) = ',)' THEN NULL
|
||||
ELSE TRY_CAST(SUBSTRING(vol, CHARINDEX(',', vol) + 1, LEN(vol) - CHARINDEX(',', vol) - 1) AS INT)
|
||||
END AS upper_bound,
|
||||
price,
|
||||
math
|
||||
FROM
|
||||
usmidsap02.ubm.pricequote.target_prices_view;
|
||||
|
||||
|
||||
SELECT TOP 100 * FROM rlarp.target_prices;
|
||||
|
||||
SELECT * FROM rlarp.target_prices tp
|
||||
WHERE
|
||||
stlc = 'XNS0T1G3'
|
||||
AND ds = 'v1:T..PLT..'
|
||||
AND chan = 'DIR'
|
||||
AND tier = 1
|
||||
AND 1.01 >= lower_bound
|
||||
AND (1.01 < upper_bound OR upper_bound IS NULL);
|
Loading…
Reference in New Issue
Block a user