break our approval versus guidance logic in postgres
This commit is contained in:
parent
2cc7204c7f
commit
ad6d3d60f0
@ -1,5 +1,5 @@
|
|||||||
SELECT
|
SELECT
|
||||||
ui_json->'details'
|
ui_json->'data'
|
||||||
FROM pricequote.single_price_call(
|
FROM pricequote.single_price_call(
|
||||||
'FARM0001',
|
'FARM0001',
|
||||||
'KEYB0001',
|
'KEYB0001',
|
||||||
@ -7,16 +7,18 @@
|
|||||||
'v1:T..CSE..D',
|
'v1:T..CSE..D',
|
||||||
50000
|
50000
|
||||||
) f;
|
) f;
|
||||||
--
|
|
||||||
-- SELECT
|
|
||||||
-- ui_json->'details'
|
SELECT
|
||||||
-- FROM pricequote.single_price_call(
|
ui_json->'data'
|
||||||
-- 'FARM0001',
|
FROM pricequote.single_price_call(
|
||||||
-- 'KEYB0001',
|
'GRIF0001',
|
||||||
-- 'HZP3E103E21D050',
|
'GRIF0001',
|
||||||
-- 'v1:C..BDL..',
|
'XNS0T1G3G18B096',
|
||||||
-- 50000
|
'v1:B..PLT..',
|
||||||
-- ) f;
|
9600
|
||||||
|
) f;
|
||||||
|
|
||||||
--
|
--
|
||||||
-- SELECT
|
-- SELECT
|
||||||
-- ui_json
|
-- ui_json
|
||||||
|
72
procs/approval_logic.pg.sql
Normal file
72
procs/approval_logic.pg.sql
Normal file
@ -0,0 +1,72 @@
|
|||||||
|
CREATE OR REPLACE FUNCTION pricequote.approval_logic(
|
||||||
|
_target numeric(20,5),
|
||||||
|
_last_norm numeric(20,5),
|
||||||
|
_list_eff numeric(20,5),
|
||||||
|
_last_date date,
|
||||||
|
_floor_pct numeric(10,5) DEFAULT 0.95,
|
||||||
|
_cap_last_pct numeric(10,5) DEFAULT 1.00,
|
||||||
|
_cap_list_pct numeric(10,5) DEFAULT 1.00
|
||||||
|
)
|
||||||
|
RETURNS TABLE (
|
||||||
|
approval_price numeric(20,5),
|
||||||
|
approval_reason text
|
||||||
|
)
|
||||||
|
LANGUAGE plpgsql AS $$
|
||||||
|
DECLARE
|
||||||
|
base_price numeric(20,5);
|
||||||
|
after_floor numeric(20,5);
|
||||||
|
after_cap_last numeric(20,5);
|
||||||
|
final_price numeric(20,5);
|
||||||
|
reason text := '';
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
-- Early exit if nothing to work with
|
||||||
|
IF _target IS NULL AND _last_norm IS NULL AND _list_eff IS NULL THEN
|
||||||
|
RETURN QUERY SELECT NULL::numeric, 'No target, last, or list available';
|
||||||
|
RETURN;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
|
||||||
|
-- Pick starting base price
|
||||||
|
base_price := COALESCE(_target, _last_norm, _list_eff);
|
||||||
|
|
||||||
|
-- Step 1: use base price unless it's more than x% below last price
|
||||||
|
after_floor := base_price;
|
||||||
|
IF _last_norm IS NOT NULL THEN
|
||||||
|
after_floor := GREATEST(base_price, ROUND(_last_norm*_floor_pct,5));
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Step 2: use price from previous step but don't allow it to be x% above last price
|
||||||
|
after_cap_last := after_floor;
|
||||||
|
IF _last_norm IS NOT NULL THEN
|
||||||
|
after_cap_last := LEAST(after_floor, ROUND(_last_norm*_cap_last_pct,5));
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- cap to list (binds if it lowers price)
|
||||||
|
final_price := after_cap_last;
|
||||||
|
IF _list_eff IS NOT NULL THEN
|
||||||
|
final_price := LEAST(after_cap_last, ROUND(_list_eff*_cap_list_pct,5));
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Reason text
|
||||||
|
reason :=
|
||||||
|
CASE
|
||||||
|
WHEN _target IS NOT NULL THEN 'Using target price'
|
||||||
|
WHEN _last_norm IS NOT NULL THEN 'Using last price as base'
|
||||||
|
WHEN _list_eff IS NOT NULL THEN 'Using list price as base'
|
||||||
|
END;
|
||||||
|
|
||||||
|
IF _last_norm IS NOT NULL AND after_floor > base_price THEN
|
||||||
|
reason := 'Last price drop limit';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF _last_norm IS NOT NULL AND after_cap_last < after_floor THEN
|
||||||
|
reason := 'Last price increase limit';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF _list_eff IS NOT NULL AND final_price < after_cap_last THEN
|
||||||
|
reason := 'List price ceiling';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
RETURN QUERY SELECT final_price, reason;
|
||||||
|
END $$;
|
@ -3,11 +3,14 @@ CREATE OR REPLACE FUNCTION pricequote.guidance_logic(
|
|||||||
_last_norm numeric(20,5),
|
_last_norm numeric(20,5),
|
||||||
_list_eff numeric(20,5),
|
_list_eff numeric(20,5),
|
||||||
_last_date date,
|
_last_date date,
|
||||||
_floor_pct numeric(10,5) DEFAULT 0.05,
|
_floor_pct numeric(10,5) DEFAULT 0.95,
|
||||||
_cap_last_pct numeric(10,5) DEFAULT 1.00,
|
_cap_last_pct numeric(10,5) DEFAULT 1.00,
|
||||||
_cap_list_pct numeric(10,5) DEFAULT 1.00
|
_cap_list_pct numeric(10,5) DEFAULT 1.00
|
||||||
)
|
)
|
||||||
RETURNS TABLE (guidance_price numeric(20,5), guidance_reason text)
|
RETURNS TABLE (
|
||||||
|
guidance_price numeric(20,5),
|
||||||
|
guidance_reason text
|
||||||
|
)
|
||||||
LANGUAGE plpgsql AS $$
|
LANGUAGE plpgsql AS $$
|
||||||
DECLARE
|
DECLARE
|
||||||
base_price numeric(20,5);
|
base_price numeric(20,5);
|
||||||
@ -15,55 +18,39 @@ DECLARE
|
|||||||
after_cap_last numeric(20,5);
|
after_cap_last numeric(20,5);
|
||||||
final_price numeric(20,5);
|
final_price numeric(20,5);
|
||||||
reason text := '';
|
reason text := '';
|
||||||
|
|
||||||
BEGIN
|
BEGIN
|
||||||
IF _target IS NULL THEN
|
|
||||||
RETURN QUERY SELECT NULL::numeric, 'No target price available';
|
-- Early exit if nothing to work with
|
||||||
|
IF _target IS NULL AND _last_norm IS NULL AND _list_eff IS NULL THEN
|
||||||
|
RETURN QUERY SELECT NULL::numeric, 'No target, last, or list available';
|
||||||
RETURN;
|
RETURN;
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
base_price := _target;
|
|
||||||
|
|
||||||
-- floor (binds if it raises price)
|
-- Pick starting base price
|
||||||
after_floor := base_price;
|
base_price := COALESCE(_target, _last_norm, _list_eff);
|
||||||
IF _last_norm IS NOT NULL AND _floor_pct > 0 THEN
|
-- Reason text
|
||||||
after_floor := GREATEST(base_price, ROUND(_last_norm*(1-_floor_pct),5));
|
reason :=
|
||||||
|
CASE
|
||||||
|
WHEN _target IS NOT NULL THEN 'Using target price'
|
||||||
|
WHEN _last_norm IS NOT NULL THEN 'Using last price as base'
|
||||||
|
WHEN _list_eff IS NOT NULL THEN 'Using list price as base'
|
||||||
|
END;
|
||||||
|
|
||||||
|
-- Step 1: use base price less than last price, use last price
|
||||||
|
IF base_price < _last_norm THEN
|
||||||
|
base_price := _last_norm;
|
||||||
|
reason := 'Last price';
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
-- cap to last (binds if it lowers price)
|
-- Step 2: use price from previous step but don't allow it to be x% above last price
|
||||||
after_cap_last := after_floor;
|
IF base_price > _list_eff THEN
|
||||||
IF _last_norm IS NOT NULL THEN
|
base_price := _list_eff;
|
||||||
after_cap_last := LEAST(after_floor, ROUND(_last_norm*_cap_last_pct,5));
|
reason := 'List price ceiling';
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
-- cap to list (binds if it lowers price)
|
final_price := base_price;
|
||||||
final_price := after_cap_last;
|
|
||||||
IF _list_eff IS NOT NULL THEN
|
|
||||||
final_price := LEAST(after_cap_last, ROUND(_list_eff*_cap_list_pct,5));
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
-- build reason
|
|
||||||
IF _last_norm IS NULL AND _list_eff IS NULL THEN
|
|
||||||
reason := 'No prior sale or list; using target price';
|
|
||||||
ELSE
|
|
||||||
reason := 'Using target price';
|
|
||||||
IF _last_norm IS NOT NULL AND _floor_pct > 0 AND after_floor > base_price THEN
|
|
||||||
reason := reason || format(', floored to %s%% below last price', to_char((_floor_pct*100)::numeric,'FM999990.##'));
|
|
||||||
END IF;
|
|
||||||
IF _last_norm IS NOT NULL AND after_cap_last < after_floor THEN
|
|
||||||
IF _cap_last_pct = 1 THEN
|
|
||||||
reason := reason || ', capped to not exceed last price';
|
|
||||||
ELSE
|
|
||||||
reason := reason || format(', capped to %s%% of last price', to_char((_cap_last_pct*100)::numeric,'FM999990.##'));
|
|
||||||
END IF;
|
|
||||||
END IF;
|
|
||||||
IF _list_eff IS NOT NULL AND final_price < after_cap_last THEN
|
|
||||||
IF _cap_list_pct = 1 THEN
|
|
||||||
reason := reason || ', capped to not exceed list price';
|
|
||||||
ELSE
|
|
||||||
reason := reason || format(', capped to %s%% of list price', to_char((_cap_list_pct*100)::numeric,'FM999990.##'));
|
|
||||||
END IF;
|
|
||||||
END IF;
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
RETURN QUERY SELECT final_price, reason;
|
RETURN QUERY SELECT final_price, reason;
|
||||||
END $$;
|
END $$;
|
@ -46,6 +46,8 @@ CREATE TABLE pricequote.queue (
|
|||||||
list_relevance TEXT,
|
list_relevance TEXT,
|
||||||
guidance_price NUMERIC,
|
guidance_price NUMERIC,
|
||||||
guidance_reason TEXT,
|
guidance_reason TEXT,
|
||||||
|
approval_price NUMERIC,
|
||||||
|
approval_reason TEXT,
|
||||||
expl JSONB,
|
expl JSONB,
|
||||||
ui_json JSONB
|
ui_json JSONB
|
||||||
);
|
);
|
||||||
@ -337,20 +339,32 @@ BEGIN
|
|||||||
UPDATE pricequote.queue q
|
UPDATE pricequote.queue q
|
||||||
SET
|
SET
|
||||||
guidance_price = s.guidance_price,
|
guidance_price = s.guidance_price,
|
||||||
guidance_reason = s.guidance_reason
|
guidance_reason = s.guidance_reason,
|
||||||
|
approval_price = s.approval_price,
|
||||||
|
approval_reason = s.approval_reason
|
||||||
FROM (
|
FROM (
|
||||||
SELECT
|
SELECT
|
||||||
q2.ctid,
|
q2.ctid,
|
||||||
g.guidance_price,
|
g.guidance_price,
|
||||||
g.guidance_reason
|
g.guidance_reason,
|
||||||
FROM pricequote.queue q2
|
a.approval_price,
|
||||||
|
a.approval_reason
|
||||||
|
FROM
|
||||||
|
pricequote.queue q2
|
||||||
JOIN LATERAL pricequote.guidance_logic(
|
JOIN LATERAL pricequote.guidance_logic(
|
||||||
q2.tprice,
|
q2.tprice,
|
||||||
q2.last_price_norm,
|
q2.last_price_norm,
|
||||||
q2.listprice_eff,
|
q2.listprice_eff,
|
||||||
q2.last_date,
|
q2.last_date,
|
||||||
.05, 1.0, 1.0
|
.95, 1.0, 1.0
|
||||||
) g ON TRUE
|
) g ON TRUE
|
||||||
|
JOIN LATERAL pricequote.approval_logic(
|
||||||
|
q2.tprice,
|
||||||
|
q2.last_price_norm,
|
||||||
|
q2.listprice_eff,
|
||||||
|
q2.last_date,
|
||||||
|
.95, 1.0, 1.0
|
||||||
|
) a ON TRUE
|
||||||
) s
|
) s
|
||||||
WHERE q.ctid = s.ctid;
|
WHERE q.ctid = s.ctid;
|
||||||
-- 4:33
|
-- 4:33
|
||||||
@ -408,7 +422,9 @@ BEGIN
|
|||||||
'list_relevance', q.list_relevance
|
'list_relevance', q.list_relevance
|
||||||
),
|
),
|
||||||
'guidance_price', q.guidance_price,
|
'guidance_price', q.guidance_price,
|
||||||
'guidance_reason', q.guidance_reason
|
'guidance_reason', q.guidance_reason,
|
||||||
|
'approval_price', q.approval_price,
|
||||||
|
'approval_reason', q.approval_reason
|
||||||
),
|
),
|
||||||
ui_json = jsonb_build_object(
|
ui_json = jsonb_build_object(
|
||||||
'details', jsonb_build_array(
|
'details', jsonb_build_array(
|
||||||
|
@ -89,6 +89,8 @@ RETURNS TABLE (
|
|||||||
list_relevance TEXT,
|
list_relevance TEXT,
|
||||||
guidance_price NUMERIC,
|
guidance_price NUMERIC,
|
||||||
guidance_reason TEXT,
|
guidance_reason TEXT,
|
||||||
|
approval_price NUMERIC,
|
||||||
|
approval_reason TEXT,
|
||||||
expl JSONB,
|
expl JSONB,
|
||||||
ui_json JSONB
|
ui_json JSONB
|
||||||
) AS $$
|
) AS $$
|
||||||
@ -148,6 +150,8 @@ DECLARE
|
|||||||
------------step 6 compute guidance------------
|
------------step 6 compute guidance------------
|
||||||
_guidance_price NUMERIC;
|
_guidance_price NUMERIC;
|
||||||
_guidance_reason TEXT;
|
_guidance_reason TEXT;
|
||||||
|
_approval_price NUMERIC;
|
||||||
|
_approval_reason TEXT;
|
||||||
------------step 7 build json------------------
|
------------step 7 build json------------------
|
||||||
_expl JSONB := '{}'::jsonb;
|
_expl JSONB := '{}'::jsonb;
|
||||||
_ui_json JSONB := '{}'::jsonb;
|
_ui_json JSONB := '{}'::jsonb;
|
||||||
@ -372,10 +376,16 @@ BEGIN
|
|||||||
SELECT
|
SELECT
|
||||||
gl.guidance_price
|
gl.guidance_price
|
||||||
,gl.guidance_reason
|
,gl.guidance_reason
|
||||||
|
,al.approval_price
|
||||||
|
,al.approval_reason
|
||||||
INTO
|
INTO
|
||||||
_guidance_price
|
_guidance_price
|
||||||
,_guidance_reason
|
,_guidance_reason
|
||||||
FROM pricequote.guidance_logic(_tprice, _last_price_norm, _listprice_eff, _last_date, .05, 1.0, 1.0) gl;
|
,_approval_price
|
||||||
|
,_approval_reason
|
||||||
|
FROM
|
||||||
|
pricequote.guidance_logic(_tprice, _last_price_norm, _listprice_eff, _last_date, .95, 1.0, 1.0) gl
|
||||||
|
CROSS JOIN pricequote.approval_logic(_tprice, _last_price_norm, _listprice_eff, _last_date, .95, 1.0, 1.0) al;
|
||||||
|
|
||||||
------------------------------------------------------------------
|
------------------------------------------------------------------
|
||||||
-- Step 8: Build explanation JSON
|
-- Step 8: Build explanation JSON
|
||||||
@ -434,7 +444,9 @@ BEGIN
|
|||||||
'list_relevance', _list_relevance
|
'list_relevance', _list_relevance
|
||||||
),
|
),
|
||||||
'guidance_price', _guidance_price,
|
'guidance_price', _guidance_price,
|
||||||
'guidance_reason', _guidance_reason
|
'guidance_reason', _guidance_reason,
|
||||||
|
'approval_price', _approval_price,
|
||||||
|
'approval_reason', _approval_reason
|
||||||
);
|
);
|
||||||
|
|
||||||
------------------------------------------------------------------
|
------------------------------------------------------------------
|
||||||
@ -582,6 +594,7 @@ BEGIN
|
|||||||
_tprice, _tmath, _volume_range,
|
_tprice, _tmath, _volume_range,
|
||||||
_list_price, _list_code, _listprice_eff, _list_relevance,
|
_list_price, _list_code, _listprice_eff, _list_relevance,
|
||||||
_guidance_price, _guidance_reason,
|
_guidance_price, _guidance_reason,
|
||||||
|
_approval_price, _approval_reason,
|
||||||
_expl, _ui_json;
|
_expl, _ui_json;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$ LANGUAGE plpgsql;
|
||||||
|
Loading…
Reference in New Issue
Block a user