319 lines
9.7 KiB
PL/PgSQL
319 lines
9.7 KiB
PL/PgSQL
-- DROP FUNCTION IF EXISTS pricequote.single_price_call() CASCADE;
|
|
|
|
CREATE OR REPLACE FUNCTION pricequote.single_price_call(
|
|
_bill TEXT,
|
|
_ship TEXT,
|
|
_part TEXT,
|
|
_v1ds TEXT,
|
|
_vol NUMERIC
|
|
)
|
|
RETURNS TABLE (
|
|
bill TEXT,
|
|
ship TEXT,
|
|
part TEXT,
|
|
stlc TEXT,
|
|
v1ds TEXT,
|
|
vol NUMERIC,
|
|
chan TEXT,
|
|
cust TEXT,
|
|
tier TEXT,
|
|
pltq NUMERIC,
|
|
plevel TEXT,
|
|
partgroup TEXT,
|
|
-- history JSONB,
|
|
last_price NUMERIC,
|
|
last_qty NUMERIC,
|
|
last_dataseg TEXT,
|
|
last_date DATE,
|
|
last_order TEXT,
|
|
last_quote TEXT,
|
|
last_source TEXT,
|
|
tprice NUMERIC,
|
|
tmath JSONB,
|
|
volume_range TEXT,
|
|
listprice NUMERIC,
|
|
listcode TEXT,
|
|
guidance_price NUMERIC,
|
|
guidance_reason TEXT,
|
|
expl JSONB,
|
|
ui_json JSONB
|
|
) AS $$
|
|
DECLARE
|
|
_pltq NUMERIC;
|
|
_chan TEXT;
|
|
_tier TEXT;
|
|
_cust TEXT;
|
|
_plevel TEXT;
|
|
_partgroup TEXT;
|
|
_stlc TEXT;
|
|
_tprice NUMERIC;
|
|
_tmath JSONB;
|
|
_volume_range TEXT;
|
|
_list_price NUMERIC;
|
|
_list_code TEXT;
|
|
_guidance_price NUMERIC;
|
|
_guidance_reason TEXT;
|
|
_hist JSONB := '{}'::jsonb;
|
|
-- Last sale/quote/volume/segment fields
|
|
_mrs JSONB;
|
|
_mrq JSONB;
|
|
_lvs JSONB;
|
|
_lvq JSONB;
|
|
_dss JSONB;
|
|
_dsq JSONB;
|
|
|
|
-- Precedence chain
|
|
_last_price NUMERIC;
|
|
_last_qty NUMERIC;
|
|
_last_dataseg TEXT;
|
|
_last_date DATE;
|
|
_last_order TEXT;
|
|
_last_quote TEXT;
|
|
_last_source TEXT;
|
|
_expl JSONB := '{}'::jsonb;
|
|
_ui_json JSONB := '{}'::jsonb;
|
|
BEGIN
|
|
------------------------------------------------------------------
|
|
-- Step 1: Resolve customer metadata
|
|
------------------------------------------------------------------
|
|
SELECT
|
|
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,
|
|
CASE SUBSTRING(bc.cclass, 2, 3)
|
|
WHEN 'DIR' THEN bc.tier
|
|
ELSE COALESCE(sc.tier, bc.tier)
|
|
END,
|
|
CASE SUBSTRING(bc.cclass, 2, 3)
|
|
WHEN 'DIS' THEN
|
|
CASE SUBSTRING(sc.cclass, 2, 3)
|
|
WHEN 'DIS' THEN bc.dba
|
|
ELSE sc.dba
|
|
END
|
|
ELSE bc.dba
|
|
END,
|
|
CASE SUBSTRING(bc.cclass, 2, 3)
|
|
WHEN 'DIS' THEN
|
|
CASE SUBSTRING(sc.cclass, 2, 3)
|
|
WHEN 'DIS' THEN sc.plevel
|
|
ELSE bc.plevel
|
|
END
|
|
ELSE bc.plevel
|
|
END,
|
|
i.partgroup,
|
|
substring(_part,1,8)
|
|
INTO _pltq, _chan, _tier, _cust, _plevel, _partgroup, _stlc
|
|
FROM rlarp.cust bc
|
|
LEFT JOIN rlarp.cust sc ON sc.code = _ship
|
|
LEFT JOIN "CMS.CUSLG".itemm i ON i.item = _part
|
|
WHERE bc.code = _bill;
|
|
|
|
------------------------------------------------------------------
|
|
-- Step 2: Target price logic
|
|
------------------------------------------------------------------
|
|
SELECT tp.price,
|
|
to_json(tp.math),
|
|
tp.vol::text
|
|
INTO _tprice, _tmath, _volume_range
|
|
FROM pricequote.target_prices tp
|
|
WHERE tp.stlc = _stlc
|
|
AND tp.ds = _v1ds
|
|
AND tp.chan = _chan
|
|
AND tp.tier = _tier
|
|
AND FLOOR(_vol / NULLIF(_pltq, 0))::int <@ tp.vol;
|
|
|
|
------------------------------------------------------------------
|
|
-- Step 3: Last sale/quote/volume/segment data
|
|
------------------------------------------------------------------
|
|
SELECT
|
|
lp.part_stats
|
|
INTO
|
|
_hist
|
|
FROM pricequote.lastpricedetail lp
|
|
WHERE lp.customer = _cust
|
|
AND lp.partgroup = _partgroup;
|
|
|
|
-- Extract top-level keys
|
|
_mrs := _hist -> 'mrs';
|
|
_mrq := _hist -> 'mrq';
|
|
_lvs := _hist -> 'lvs';
|
|
_lvq := _hist -> 'lvq';
|
|
|
|
-- Extract per-datasegment block matching the input v1ds
|
|
_dss := (_hist -> _v1ds) -> 'dss';
|
|
_dsq := (_hist -> _v1ds) -> 'dsq';
|
|
|
|
-- Precedence chain for last_price, etc.
|
|
_last_price := COALESCE(
|
|
(_dsq->>'price')::numeric,
|
|
(_dss->>'price')::numeric,
|
|
(_mrq->>'price')::numeric,
|
|
(_mrs->>'price')::numeric
|
|
);
|
|
_last_qty := COALESCE(
|
|
(_dsq->>'qty')::numeric,
|
|
(_dss->>'qty')::numeric,
|
|
(_mrq->>'qty')::numeric,
|
|
(_mrs->>'qty')::numeric
|
|
);
|
|
_last_dataseg := COALESCE(
|
|
_dsq->>'datasegment',
|
|
_dss->>'datasegment',
|
|
_mrq->>'datasegment',
|
|
_mrs->>'datasegment'
|
|
);
|
|
_last_date := COALESCE(
|
|
(_dsq->>'odate')::date,
|
|
(_dss->>'odate')::date,
|
|
(_mrq->>'odate')::date,
|
|
(_mrs->>'odate')::date
|
|
);
|
|
_last_order := COALESCE(
|
|
_dsq->>'ordnum',
|
|
_dss->>'ordnum',
|
|
_mrq->>'ordnum',
|
|
_mrs->>'ordnum'
|
|
);
|
|
_last_quote := COALESCE(
|
|
_dsq->>'quoten',
|
|
_dss->>'quoten',
|
|
_mrq->>'quoten',
|
|
_mrs->>'quoten'
|
|
);
|
|
_last_source := CASE
|
|
WHEN _dsq->>'price' IS NOT NULL THEN 'dsq'
|
|
WHEN _dss->>'price' IS NOT NULL THEN 'dss'
|
|
WHEN _mrq->>'price' IS NOT NULL THEN 'mrq'
|
|
WHEN _mrs->>'price' IS NOT NULL THEN 'mrs'
|
|
ELSE NULL
|
|
END;
|
|
|
|
------------------------------------------------------------------
|
|
-- Step 4: List price
|
|
------------------------------------------------------------------
|
|
SELECT
|
|
pr.price::numeric(20,5), pr.jcplcd
|
|
INTO
|
|
_list_price, _list_code
|
|
FROM
|
|
"CMS.CUSLG".IPRCBHC i
|
|
JOIN pricequote.pricelist_ranged pr
|
|
ON pr.jcplcd = TRIM(i.jbplcd)
|
|
AND pr.jcpart = _part
|
|
AND _vol >= pr.vb_from
|
|
AND (_vol < pr.vb_to OR pr.vb_to IS NULL)
|
|
WHERE TRIM(i.jbplvl) = TRIM(_plevel)
|
|
AND CURRENT_DATE BETWEEN i.jbfdat AND i.jbtdat
|
|
ORDER BY pr.price ASC
|
|
LIMIT 1;
|
|
|
|
------------------------------------------------------------------
|
|
-- Step 5: Compute guidance price and embed it
|
|
------------------------------------------------------------------
|
|
SELECT
|
|
gl.guidance_price, gl.guidance_reason
|
|
INTO
|
|
_guidance_price, _guidance_reason
|
|
FROM
|
|
pricequote.guidance_logic(_tprice, _last_price, _list_price, _last_date) gl;
|
|
|
|
------------------------------------------------------------------
|
|
-- Step 6: Build explanation JSON
|
|
------------------------------------------------------------------
|
|
_expl := jsonb_build_object(
|
|
'last_price', _last_price,
|
|
'last_qty', _last_qty,
|
|
'last_dataseg', _last_dataseg,
|
|
'last_source', _last_source,
|
|
'last_date', _last_date,
|
|
'last_order', _last_order,
|
|
'last_quote', _last_quote,
|
|
'mrs', _mrs,
|
|
'mrq', _mrq,
|
|
'lvs', _lvs,
|
|
'lvq', _lvq,
|
|
'dss', _dss,
|
|
'dsq', _dsq,
|
|
'target_price', _tprice,
|
|
'target_math', _tmath,
|
|
'calculated_pallets', FLOOR(_vol / NULLIF(_pltq, 0)),
|
|
'exact_pallets', ROUND(_vol / NULLIF(_pltq, 0), 5),
|
|
'customer', _cust,
|
|
'channel', _chan,
|
|
'tier', TRIM(_tier),
|
|
'list_price', _list_price,
|
|
'list_code', _list_code,
|
|
'guidance_price', _guidance_price,
|
|
'guidance_reason', _guidance_reason
|
|
);
|
|
|
|
------------------------------------------------------------------
|
|
-- Step 7: Build UI JSON (optional, similar to MSSQL)
|
|
------------------------------------------------------------------
|
|
_ui_json := jsonb_build_object(
|
|
'details', jsonb_build_array(
|
|
jsonb_build_object(
|
|
'label', 'History',
|
|
'details', jsonb_build_array(
|
|
jsonb_build_object(
|
|
'label', CASE WHEN _last_price IS NOT NULL THEN 'Last Sale: ' || _last_date ELSE 'No Recent' END,
|
|
'value', COALESCE(_last_price,0),
|
|
'type', 'currency',
|
|
'note', CASE WHEN _last_price IS NOT NULL THEN _last_source ||
|
|
CASE WHEN COALESCE(_last_order, '0') = '0' THEN ' Qt# ' || COALESCE(_last_quote, '') ELSE ' Ord# ' || COALESCE(_last_order, '') END
|
|
ELSE NULL END
|
|
)
|
|
)
|
|
),
|
|
jsonb_build_object(
|
|
'label', 'List',
|
|
'details', jsonb_build_array(
|
|
jsonb_build_object(
|
|
'label', 'List:' || COALESCE(_list_code, ''),
|
|
'value', _list_price,
|
|
'type', 'currency',
|
|
'note', _plevel
|
|
)
|
|
)
|
|
),
|
|
jsonb_build_object(
|
|
'label', 'Target Support',
|
|
'details', _tmath -- You may need to transform this to match the MSSQL panel
|
|
),
|
|
jsonb_build_object(
|
|
'label', 'Guidance',
|
|
'details', jsonb_build_array(
|
|
jsonb_build_object(
|
|
'label', 'Price',
|
|
'value', _guidance_price,
|
|
'type', 'currency',
|
|
'note', _guidance_reason
|
|
)
|
|
)
|
|
)
|
|
),
|
|
'data', _expl
|
|
);
|
|
|
|
------------------------------------------------------------------
|
|
-- Final: Return row
|
|
------------------------------------------------------------------
|
|
RETURN QUERY
|
|
SELECT
|
|
_bill, _ship, _part, _stlc, _v1ds, _vol,
|
|
_chan, _cust, _tier, _pltq, _plevel, _partgroup,
|
|
-- _hist,
|
|
_last_price, _last_qty, _last_dataseg, _last_date, _last_order, _last_quote, _last_source,
|
|
_tprice, _tmath, _volume_range,
|
|
_list_price, _list_code,
|
|
_guidance_price, _guidance_reason,
|
|
_expl, _ui_json;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|