153 lines
4.0 KiB
PL/PgSQL
153 lines
4.0 KiB
PL/PgSQL
DROP FUNCTION rlarp.get_guidance_dseg;
|
|
CREATE OR REPLACE FUNCTION rlarp.get_guidance_dseg(_bill text, _ship text, _stlc text, _dseg 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;
|
|
_item text;
|
|
_cust text;
|
|
_v1ds text;
|
|
_v0ds text;
|
|
_v1tp jsonb;
|
|
_v0tp jsonb;
|
|
_chan text;
|
|
_regn text;
|
|
_rslt jsonb;
|
|
_targ jsonb;
|
|
_list jsonb;
|
|
_iidx jsonb;
|
|
|
|
BEGIN
|
|
--_item := 'AMK06000G18B054';
|
|
--_bill := 'DIAM0004';
|
|
--_ship := 'DIAM0004';
|
|
--_qty := 5000;
|
|
--_seas := 2024;
|
|
|
|
|
|
----------------base product--------------------------------
|
|
|
|
SELECT
|
|
m.part_group
|
|
,min(i.item) item
|
|
,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
|
|
,_item
|
|
,_stlc
|
|
,_v1ds
|
|
,_v0ds
|
|
,_iidx
|
|
FROM
|
|
"CMS.CUSLG".itemmv i
|
|
INNER JOIN rlarp.molds m ON
|
|
m.stlc = i.stlc
|
|
WHERE
|
|
i.stlc = _stlc
|
|
AND i.v1ds = _dseg
|
|
GROUP BY
|
|
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));
|
|
_rslt := jsonb_build_object('mold',_mold,'v1ds',_v1ds,'v0ds',_v0ds,'stlc',_stlc)||_iidx;
|
|
--RAISE NOTICE 'item data %', _iidx;
|
|
|
|
----------------channel-------------------------------------
|
|
|
|
SELECT rlarp.channel_code(_bill, _ship) INTO _chan;
|
|
_rslt := _rslt||jsonb_build_object('chan',_chan);
|
|
--RAISE NOTICE '%', _chan;
|
|
|
|
----------------customer------------------------------------
|
|
|
|
SELECT dba INTO _cust FROM rlarp.cust WHERE code = CASE WHEN _chan = 'DRP' THEN _ship ELSE _bill END ;
|
|
_rslt = _rslt||jsonb_build_object('cust',_cust);
|
|
--RAISE NOTICE 'cust %', _cust;
|
|
|
|
----------------price history-------------------------------
|
|
SELECT _rslt||jsonb_build_object('hist',rlarp.gethist(_mold, _cust)) 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 ppricing-------------------------------
|
|
SELECT coalesce(rlarp.get_list(_bill, _ship, _item, _qty),'{}'::jsonb) INTO _list;
|
|
_rslt := _rslt||_list;
|
|
--RAISE NOTICE 'list: %', jsonb_pretty(_list);
|
|
|
|
RETURN _rslt;
|
|
|
|
END;
|
|
$func$;
|