join in cost and volume, fix last price cross join
This commit is contained in:
parent
3cc82d14c0
commit
23b3962313
@ -151,31 +151,40 @@ BEGIN
|
|||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
-- 4) History: store hist, extract last_* with precedence helper
|
-- 4) History: store hist, extract last_* with precedence helper
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
UPDATE pricequote.queue q
|
UPDATE pricequote.queue q
|
||||||
SET
|
SET
|
||||||
hist = lp.part_stats,
|
hist = x.part_stats, -- from the correlated subquery
|
||||||
last_price = (j->>'price')::NUMERIC,
|
last_price = (j->>'price')::NUMERIC,
|
||||||
last_qty = (j->>'qty')::NUMERIC,
|
last_qty = (j->>'qty')::NUMERIC,
|
||||||
last_dataseg = j->>'datasegment',
|
last_dataseg = j->>'datasegment',
|
||||||
last_date = (j->>'odate')::DATE,
|
last_date = (j->>'odate')::DATE,
|
||||||
last_order = j->>'ordnum',
|
last_order = j->>'ordnum',
|
||||||
last_quote = j->>'quoten',
|
last_quote = j->>'quoten',
|
||||||
last_source = j->>'source',
|
last_source = j->>'source',
|
||||||
last_isdiff = CASE
|
last_isdiff = CASE
|
||||||
WHEN (j->>'datasegment') IS NOT NULL AND q.v1ds IS NOT NULL AND (j->>'datasegment') <> q.v1ds
|
WHEN (j->>'datasegment') IS NOT NULL
|
||||||
THEN 'Last Sale Diff Part'
|
AND q.v1ds IS NOT NULL
|
||||||
END,
|
AND (j->>'datasegment') <> q.v1ds
|
||||||
last_v0ds = (CASE SUBSTRING(j->>'datasegment', 4, 1) WHEN 'B' THEN 'B' ELSE 'C' END)
|
THEN 'Last Sale Diff Part'
|
||||||
|| (CASE SUBSTRING(j->>'datasegment', 6, 1) WHEN 'L' THEN 'L' WHEN 'P' THEN 'P' ELSE '' END)
|
END,
|
||||||
FROM (
|
last_v0ds = (CASE SUBSTRING(j->>'datasegment', 4, 1)
|
||||||
SELECT q2.ctid, pricequote.pick_last_price_from_hist(lp2.part_stats, q2.v1ds) AS j
|
WHEN 'B' THEN 'B' ELSE 'C' END)
|
||||||
FROM pricequote.queue q2
|
|| (CASE SUBSTRING(j->>'datasegment', 6, 1)
|
||||||
JOIN pricequote.lastpricedetail lp2
|
WHEN 'L' THEN 'L'
|
||||||
ON lp2.customer = q2.cust
|
WHEN 'P' THEN 'P'
|
||||||
AND lp2.partgroup = q2.partgroup
|
ELSE '' END)
|
||||||
) x
|
FROM (
|
||||||
JOIN pricequote.lastpricedetail lp ON TRUE
|
SELECT
|
||||||
WHERE q.ctid = x.ctid;
|
q2.ctid,
|
||||||
|
lp2.part_stats,
|
||||||
|
pricequote.pick_last_price_from_hist(lp2.part_stats, q2.v1ds) AS j
|
||||||
|
FROM pricequote.queue q2
|
||||||
|
JOIN pricequote.lastpricedetail lp2
|
||||||
|
ON lp2.customer = q2.cust
|
||||||
|
AND lp2.partgroup = q2.partgroup
|
||||||
|
) AS x
|
||||||
|
WHERE q.ctid = x.ctid;
|
||||||
|
-- 2 min 3 sec
|
||||||
|
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
-- 5) Target (requested v1ds): tprice, tmath, volume_range
|
-- 5) Target (requested v1ds): tprice, tmath, volume_range
|
||||||
@ -183,7 +192,7 @@ BEGIN
|
|||||||
UPDATE pricequote.queue q
|
UPDATE pricequote.queue q
|
||||||
SET
|
SET
|
||||||
tprice = tp.price,
|
tprice = tp.price,
|
||||||
tmath = tp.math,
|
tmath = to_json(tp.math),
|
||||||
volume_range = tp.vol::TEXT
|
volume_range = tp.vol::TEXT
|
||||||
FROM pricequote.target_prices tp
|
FROM pricequote.target_prices tp
|
||||||
WHERE
|
WHERE
|
||||||
@ -192,6 +201,7 @@ BEGIN
|
|||||||
AND tp.chan = q.chan
|
AND tp.chan = q.chan
|
||||||
AND tp.tier = q.tier
|
AND tp.tier = q.tier
|
||||||
AND FLOOR(q.vol / NULLIF(q.pltq, 0))::INT <@ tp.vol;
|
AND FLOOR(q.vol / NULLIF(q.pltq, 0))::INT <@ tp.vol;
|
||||||
|
-- 22 seconds
|
||||||
|
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
-- 6) Target for last_dataseg (tprice_last)
|
-- 6) Target for last_dataseg (tprice_last)
|
||||||
@ -207,23 +217,40 @@ BEGIN
|
|||||||
AND tp2.chan = q.chan
|
AND tp2.chan = q.chan
|
||||||
AND tp2.tier = q.tier
|
AND tp2.tier = q.tier
|
||||||
AND FLOOR(q.vol / NULLIF(q.pltq, 0))::INT <@ tp2.vol;
|
AND FLOOR(q.vol / NULLIF(q.pltq, 0))::INT <@ tp2.vol;
|
||||||
|
-- 17 sec
|
||||||
|
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
-- 7) Cost data for requested v1ds and last_dataseg
|
-- 7) Cost data for requested v1ds and last_dataseg
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
UPDATE pricequote.queue q
|
UPDATE pricequote.queue q
|
||||||
SET
|
SET
|
||||||
curstd = i_req.curstdus,
|
curstd = CASE WHEN COALESCE(q.customized,'') = '' THEN q.curstd_orig ELSE COALESCE(s.v1_cur, s.v0_cur) END,
|
||||||
futstd = i_req.futstdus
|
futstd = CASE WHEN COALESCE(q.customized,'') = '' THEN q.futstd_orig ELSE COALESCE(s.v1_fut, s.v0_fut) END,
|
||||||
FROM "CMS.CUSLG".itemm i_req
|
curstd_last = CASE WHEN COALESCE(q.last_isdiff,'') = '' THEN q.curstd_orig ELSE COALESCE(s.v1l_cur, s.v0l_cur) END,
|
||||||
WHERE i_req.item = q.part AND i_req.v1ds = q.v1ds;
|
futstd_last = CASE WHEN COALESCE(q.last_isdiff,'') = '' THEN q.futstd_orig ELSE COALESCE(s.v1l_fut, s.v0l_fut) END
|
||||||
|
FROM (
|
||||||
UPDATE pricequote.queue q
|
SELECT
|
||||||
SET
|
q2.ctid,
|
||||||
curstd_last = i_last.curstdus,
|
v1.curstdus AS v1_cur,
|
||||||
futstd_last = i_last.futstdus
|
v1.futstdus AS v1_fut,
|
||||||
FROM "CMS.CUSLG".itemm i_last
|
v0.curstdus AS v0_cur,
|
||||||
WHERE i_last.item = q.part AND i_last.v1ds = q.last_dataseg;
|
v0.futstdus AS v0_fut,
|
||||||
|
v1l.curstdus AS v1l_cur,
|
||||||
|
v1l.futstdus AS v1l_fut,
|
||||||
|
v0l.curstdus AS v0l_cur,
|
||||||
|
v0l.futstdus AS v0l_fut
|
||||||
|
FROM pricequote.queue q2
|
||||||
|
LEFT JOIN rlarp.cost_v1ds v1
|
||||||
|
ON v1.stlc = q2.stlc AND v1.v1ds = q2.v1ds
|
||||||
|
LEFT JOIN rlarp.cost_v0ds v0
|
||||||
|
ON v0.stlc = q2.stlc AND v0.v0ds = q2.v0ds
|
||||||
|
LEFT JOIN rlarp.cost_v1ds v1l
|
||||||
|
ON v1l.stlc = q2.stlc AND v1l.v1ds = q2.last_dataseg
|
||||||
|
LEFT JOIN rlarp.cost_v0ds v0l
|
||||||
|
ON v0l.stlc = q2.stlc AND v0l.v0ds = q2.last_v0ds
|
||||||
|
) AS s
|
||||||
|
WHERE q.ctid = s.ctid;
|
||||||
|
-- 28 seconds
|
||||||
|
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
-- 8) List price (lowest valid); allow open-ended ranges (vb_to IS NULL)
|
-- 8) List price (lowest valid); allow open-ended ranges (vb_to IS NULL)
|
||||||
@ -253,6 +280,7 @@ BEGIN
|
|||||||
listcode = p.jcplcd
|
listcode = p.jcplcd
|
||||||
FROM best_price p
|
FROM best_price p
|
||||||
WHERE q.ctid = p.ctid;
|
WHERE q.ctid = p.ctid;
|
||||||
|
-- 18 seconds
|
||||||
|
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
-- 9) Normalize last (when last_dataseg != v1ds) + effective list flags
|
-- 9) Normalize last (when last_dataseg != v1ds) + effective list flags
|
||||||
@ -300,16 +328,30 @@ BEGIN
|
|||||||
END,
|
END,
|
||||||
listprice_eff = CASE WHEN q.customized <> '' THEN NULL ELSE q.listprice END,
|
listprice_eff = CASE WHEN q.customized <> '' THEN NULL ELSE q.listprice END,
|
||||||
list_relevance = CASE WHEN q.customized <> '' THEN 'Ignore - Customized' ELSE '' END;
|
list_relevance = CASE WHEN q.customized <> '' THEN 'Ignore - Customized' ELSE '' END;
|
||||||
|
-- 21 seconds
|
||||||
|
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
-- 10) Guidance using normalized last + effective list
|
-- 10) Guidance using normalized last + effective list
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
UPDATE pricequote.queue q
|
UPDATE pricequote.queue q
|
||||||
SET
|
SET
|
||||||
guidance_price = g.guidance_price,
|
guidance_price = s.guidance_price,
|
||||||
guidance_reason = g.guidance_reason
|
guidance_reason = s.guidance_reason
|
||||||
FROM LATERAL pricequote.guidance_logic(q.tprice, q.last_price_norm, q.listprice_eff, q.last_date) g
|
FROM (
|
||||||
WHERE q.ctid IS NOT NULL;
|
SELECT
|
||||||
|
q2.ctid,
|
||||||
|
g.guidance_price,
|
||||||
|
g.guidance_reason
|
||||||
|
FROM pricequote.queue q2
|
||||||
|
JOIN LATERAL pricequote.guidance_logic(
|
||||||
|
q2.tprice,
|
||||||
|
q2.last_price_norm,
|
||||||
|
q2.listprice_eff,
|
||||||
|
q2.last_date
|
||||||
|
) g ON TRUE
|
||||||
|
) s
|
||||||
|
WHERE q.ctid = s.ctid;
|
||||||
|
-- 31 seconds
|
||||||
|
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
-- 11) Build expl and ui_json identical to single_price_call
|
-- 11) Build expl and ui_json identical to single_price_call
|
||||||
@ -354,7 +396,8 @@ BEGIN
|
|||||||
),
|
),
|
||||||
'targets', jsonb_build_object(
|
'targets', jsonb_build_object(
|
||||||
'target_price', q.tprice,
|
'target_price', q.tprice,
|
||||||
'target_math', q.tmath
|
'target_math', q.tmath,
|
||||||
|
'volume_range', q.volume_range
|
||||||
),
|
),
|
||||||
'list', jsonb_build_object(
|
'list', jsonb_build_object(
|
||||||
'listcode', q.listcode,
|
'listcode', q.listcode,
|
||||||
@ -454,6 +497,7 @@ BEGIN
|
|||||||
),
|
),
|
||||||
'data', q.expl
|
'data', q.expl
|
||||||
);
|
);
|
||||||
|
-- 2 minutes 33 seconds
|
||||||
|
|
||||||
--------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
-- 12) Merge back into matrix (store both expl and ui)
|
-- 12) Merge back into matrix (store both expl and ui)
|
||||||
@ -477,6 +521,7 @@ BEGIN
|
|||||||
AND o.version IN ('Actual', 'Forecast', 'Quotes')
|
AND o.version IN ('Actual', 'Forecast', 'Quotes')
|
||||||
AND o.part IS NOT NULL
|
AND o.part IS NOT NULL
|
||||||
AND SUBSTRING(o.glec, 1, 1) <= '2';
|
AND SUBSTRING(o.glec, 1, 1) <= '2';
|
||||||
|
-- 9 minutes 35 seconds
|
||||||
|
|
||||||
RAISE NOTICE 'Queue processing complete.';
|
RAISE NOTICE 'Queue processing complete.';
|
||||||
END;
|
END;
|
||||||
|
Loading…
Reference in New Issue
Block a user