195 lines
		
	
	
		
			5.6 KiB
		
	
	
	
		
			PL/PgSQL
		
	
	
	
	
	
			
		
		
	
	
			195 lines
		
	
	
		
			5.6 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;
 | 
						|
    _prem   jsonb;
 | 
						|
    _mold   text;
 | 
						|
    _item   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;
 | 
						|
    _iidx   jsonb;
 | 
						|
    _itemr  text;
 | 
						|
 | 
						|
BEGIN
 | 
						|
    --_item := 'AMK06000G18B054';
 | 
						|
    --_bill := 'DIAM0004';
 | 
						|
    --_ship := 'DIAM0004';
 | 
						|
    --_qty  := 5000;
 | 
						|
    --_seas := 2024;
 | 
						|
 | 
						|
    _v0ds := CASE split_part(substring(_dseg,4,100), '.',1) WHEN 'B' THEN 'BASE' ELSE 'COLOR' END || CASE split_part(substring(_dseg,4,100), '.',2) WHEN 'L' THEN ' LABELED' WHEN 'P' THEN ' PRINTED' ELSE '' END;
 | 
						|
    _v1ds := _dseg;
 | 
						|
 | 
						|
    ----------------base product--------------------------------
 | 
						|
    SELECT 
 | 
						|
        part_group
 | 
						|
        ,item
 | 
						|
        ,stlc
 | 
						|
        ,idxk
 | 
						|
        ,prefer
 | 
						|
    INTO 
 | 
						|
        _mold
 | 
						|
        ,_item
 | 
						|
        ,_stlc
 | 
						|
        ,_iidx
 | 
						|
        ,_itemr
 | 
						|
    FROM
 | 
						|
        (
 | 
						|
            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
 | 
						|
                ,CASE WHEN i.v1ds = _v1ds THEN 2 ELSE CASE WHEN i.v0ds = _v0ds THEN 1 ELSE 0 END END prefer
 | 
						|
            FROM 
 | 
						|
                "CMS.CUSLG".itemmv i 
 | 
						|
                INNER JOIN rlarp.molds m ON 
 | 
						|
                    m.stlc = i.stlc 
 | 
						|
            WHERE 
 | 
						|
                i.stlc = _stlc
 | 
						|
            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))
 | 
						|
                ,CASE WHEN i.v1ds = _v1ds THEN 2 ELSE CASE WHEN i.v0ds = _v0ds THEN 1 ELSE 0 END END
 | 
						|
        ) best
 | 
						|
    ORDER BY
 | 
						|
        prefer DESC
 | 
						|
    LIMIT 1;
 | 
						|
    _rslt := jsonb_build_object('mold',_mold,'v1ds',_v1ds,'v0ds',_v0ds,'stlc',_stlc,'item',_item,'item rel',_itemr,'desg',_dseg)||_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 %', _chan;
 | 
						|
 | 
						|
    ----------------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 'result %', _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 = _dseg
 | 
						|
        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$;
 |