price_api/sql/get_guidance.pg.sql

166 lines
4.5 KiB
PL/PgSQL

DROP FUNCTION rlarp.get_guidance;
CREATE OR REPLACE FUNCTION rlarp.get_guidance(_bill text, _ship text, _item text, _qty numeric, _seas int)
RETURNS jsonb
LANGUAGE plpgsql AS
--DO
$func$
DECLARE
--_item text;
--_bill text;
--_ship text;
--_qty numeric;
--_seas int;
_mold text;
_stlc text;
_cust text;
_curr text;
_rate numeric;
_v1ds text;
_v0ds text;
_v1tp jsonb;
_v0tp jsonb;
_chan text;
_regn text;
_rslt jsonb;
_targ jsonb;
_list jsonb;
_prem jsonb;
_iidx jsonb;
BEGIN
--_item := 'AMK06000G18B054';
--_bill := 'DIAM0004';
--_ship := 'DIAM0004';
--_qty := 5000;
--_seas := 2024;
----------------base product--------------------------------
SELECT
m.part_group, i.stlc, i.v1ds,i.v0ds,jsonb_strip_nulls(jsonb_build_object('assc',CASE WHEN i.assc <> '' THEN i.assc ELSE null::text END,'majg',i.majg::int,'coltier',i.coltier)) idxk
INTO
_mold,_stlc,_v1ds , _v0ds, _iidx
FROM
"CMS.CUSLG".itemmv i
INNER JOIN rlarp.molds m ON
m.stlc = i.stlc
WHERE
i.item = _item;
--RAISE NOTICE 'mold %', _mold;
--RAISE NOTICE 'v1ds %', _v1ds;
_rslt := jsonb_build_object('mold',_mold,'v1ds',_v1ds,'v0ds',_v0ds,'stlc',_stlc)||_iidx;
----------------channel-------------------------------------
SELECT rlarp.channel_code(_bill, _ship) INTO _chan;
_rslt := _rslt||jsonb_build_object('chan',_chan);
--RAISE NOTICE '%', _chan;
----------------customer------------------------------------
----------------customer------------------------------------
SELECT dba INTO _cust FROM rlarp.cust WHERE code = CASE WHEN _chan = 'DRP' THEN _ship ELSE _bill END ;
SELECT
currency,
(SELECT
x.rate
FROM
rlarp.ffcret x
WHERE
x.perd = (select fspr from rlarp.gld where drange @> current_date)
AND x.rtyp = 'MA'
and x.fcur = currency
AND x.tcur = 'US'
)
INTO
_curr
,_rate
FROM
rlarp.cust
WHERE
code = _bill;
_rslt = _rslt||jsonb_build_object('cust',_cust,'curr',_curr,'fxrate',_rate);
--RAISE NOTICE 'cust %', _cust;
----------------price history-------------------------------
SELECT _rslt||jsonb_build_object('hist',rlarp.get_hist(_mold, _v1ds, _cust, substring(_chan,1,1))) INTO _rslt ;
--RAISE NOTICE '%', _rslt;
----------------target pricing------------------------------
SELECT
jsonb_build_object(
'v0tp',
target_price,
'stdv',
stdev_price
)
INTO
_v0tp
FROM
pricequote.market_setavgprice
WHERE
mold = _stlc
AND season = _seas
AND data_segment = _v0ds
AND region = 'ALL';
_rslt := _rslt||COALESCE(_v0tp,'{}'::jsonb);
----------------target pricing------------------------------
SELECT
jsonb_build_object(
'v1tp',
target_price,
'stdv',
stdev_price
)
INTO
_v1tp
FROM
pricequote.market_setavgprice
WHERE
mold = _stlc
AND season = _seas
AND data_segment = _v1ds
AND region = 'ALL';
--RAISE NOTICE 'target: %', jsonb_pretty(_targ);
_rslt := _rslt||COALESCE(_v1tp,'{}'::jsonb);
----------------inflation index-----------------------------
RAISE NOTICE 'infaltion : %', jsonb_pretty(_iidx);
SELECT
jsonb_build_object(
'iidx'
,jsonb_build_object(
priority
,min(factor)
)
)
INTO
_iidx
FROM
rlarp.costindex
WHERE
timeframe @> current_date
AND (
attr @> _iidx
OR attr @> jsonb_build_object('stlc',_mold)
)
GROUP BY
priority;
_rslt := _rslt||COALESCE(_iidx,'{}'::jsonb);
----------------list pricing--------------------------------
SELECT coalesce(rlarp.get_list(_bill, _ship, _item, _qty),'{}'::jsonb) INTO _list;
_rslt := _rslt||_list;
--RAISE NOTICE 'list: %', jsonb_pretty(_list);
----------------get premium for quote hist gap--------------
SELECT coalesce(rlarp.get_premium(_stlc, _seas, (SELECT xchan FROM _chx WHERE chan = _chan),_rslt->'hist'->'cust'->>'ds', _v1ds),'{}'::jsonb) INTO _prem;
_rslt := _rslt||_prem;
--RAISE NOTICE 'list: %', jsonb_pretty(_list);
RETURN _rslt;
END;
$func$;