From 92e25c004e9a8bc4298f2cf13bb577221ce8470d Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Thu, 7 Aug 2025 22:54:27 -0400 Subject: [PATCH] update postgres matrix logic to use last price picker, add front matter to all scripts --- new_targets/procs/single_price_call.ms.sql | 36 +++++ new_targets/procs/single_price_call.pg.sql | 36 +++++ new_targets/scripts/matrix_guidance.pg.sql | 155 ++++++++------------- 3 files changed, 133 insertions(+), 94 deletions(-) diff --git a/new_targets/procs/single_price_call.ms.sql b/new_targets/procs/single_price_call.ms.sql index d2a1ae5..8ff792d 100644 --- a/new_targets/procs/single_price_call.ms.sql +++ b/new_targets/procs/single_price_call.ms.sql @@ -1,3 +1,39 @@ +/* +==================================================================================== + Script: single_price_call.ms.sql + Purpose: Single price call logic for a specific scenario (SQL Server) + ----------------------------------------------------------------------------------- + Description: + - Accepts a single pricing scenario (bill, ship, part, v1ds, vol) + - Enriches with customer, channel, tier, pack quantity, price level, and part group + - Looks up and applies target price, price history, list price, and guidance logic + - Builds a JSON explanation and UI JSON for the scenario + + Inputs: + - @bill, @ship, @part, @v1ds, @vol (procedure arguments) + - Reference tables: pricing.target_prices, pricing.lastpricedetail, pricing.pricelist_ranged + - Customer/item reference: rlarp.cust, CMS.CUSLG.itemm, CMS.CUSLG.IPRCBHC + + Outputs: + - Returns a single enriched row with all pricing and explanation fields + + Key Business Logic: + - Channel/tier/customer resolution based on bill/ship codes + - Target price and math lookup by segment, channel, tier, and volume + - Price history precedence and extraction via helper function + - List price selection: lowest valid price for the scenario + - Guidance logic: computed from target, last, and list prices + + Dependencies: + - pricing.guidance_logic (function) + - pricing.pick_last_price_from_hist_json (function) + + Notes: + - Designed for single-row pricing queries (API or UI) + - Assumes all referenced tables and functions exist + - See also: matrix_guidance.pg.sql for batch/matrix logic +==================================================================================== +*/ CREATE OR ALTER PROCEDURE pricing.single_price_call @bill VARCHAR(100), @ship VARCHAR(100), diff --git a/new_targets/procs/single_price_call.pg.sql b/new_targets/procs/single_price_call.pg.sql index 403e7f7..89c002e 100644 --- a/new_targets/procs/single_price_call.pg.sql +++ b/new_targets/procs/single_price_call.pg.sql @@ -1,3 +1,39 @@ +/* +==================================================================================== + Script: single_price_call.pg.sql + Purpose: Single price call logic for a specific scenario (PostgreSQL) + ----------------------------------------------------------------------------------- + Description: + - Accepts a single pricing scenario (bill, ship, part, v1ds, vol) + - Enriches with customer, channel, tier, pack quantity, price level, and part group + - Looks up and applies target price, price history, list price, and guidance logic + - Builds a JSON explanation and UI JSON for the scenario + + Inputs: + - bill, ship, part, v1ds, vol (function arguments) + - Reference tables: pricequote.target_prices, pricequote.lastpricedetail, pricequote.pricelist_ranged + - Customer/item reference: rlarp.cust, CMS.CUSLG.itemm, CMS.CUSLG.IPRCBHC + + Outputs: + - Returns a single enriched row with all pricing and explanation fields + + Key Business Logic: + - Channel/tier/customer resolution based on bill/ship codes + - Target price and math lookup by segment, channel, tier, and volume + - Price history precedence and extraction via helper function + - List price selection: lowest valid price for the scenario + - Guidance logic: computed from target, last, and list prices + + Dependencies: + - pricequote.guidance_logic (function) + - pricequote.pick_last_price_from_hist (function) + + Notes: + - Designed for single-row pricing queries (API or UI) + - Assumes all referenced tables and functions exist + - See also: matrix_guidance.pg.sql for batch/matrix logic +==================================================================================== +*/ CREATE OR REPLACE FUNCTION pricequote.single_price_call( _bill TEXT, _ship TEXT, diff --git a/new_targets/scripts/matrix_guidance.pg.sql b/new_targets/scripts/matrix_guidance.pg.sql index 7e52922..6f92a9b 100644 --- a/new_targets/scripts/matrix_guidance.pg.sql +++ b/new_targets/scripts/matrix_guidance.pg.sql @@ -1,4 +1,3 @@ --- Drop and recreate the target table DROP TABLE IF EXISTS pricequote.queue; CREATE TABLE pricequote.queue ( @@ -32,6 +31,44 @@ CREATE TABLE pricequote.queue ( partgroup TEXT ); +/* +==================================================================================== + Script: matrix_guidance.pg.sql + Purpose: Batch pricing logic for sales matrix (PostgreSQL) + ----------------------------------------------------------------------------------- + Description: + - Seeds a queue table with distinct pricing scenarios from rlarp.osm_stack + - Enriches each scenario with customer, channel, tier, pack quantity, and price level + - Looks up and applies target price, price history, list price, and guidance logic + - Builds a JSON explanation for each scenario + - Merges results back into the main sales matrix table + + Inputs: + - Source table: rlarp.osm_stack + - Pricing reference tables: pricequote.target_prices, pricequote.lastpricedetail, pricequote.pricelist_ranged + - Customer/item reference: rlarp.cust, CMS.CUSLG.itemm, CMS.CUSLG.IPRCBHC + + Outputs: + - Updates rlarp.osm_stack.pricing with a JSON explanation for each scenario + - All intermediate results are stored in pricequote.queue + + Key Business Logic: + - Channel/tier/customer resolution based on bill/ship codes + - Target price and math lookup by segment, channel, tier, and volume + - Price history precedence and extraction via helper function + - List price selection: lowest valid price for the scenario + - Guidance logic: computed from target, last, and list prices + + Dependencies: + - pricequote.guidance_logic (function) + - pricequote.pick_last_price_from_hist (function) + + Notes: + - Designed for batch/matrix pricing updates + - Assumes all referenced tables and functions exist + - See also: single_price_call.pg.sql for single-row logic +==================================================================================== +*/ CREATE INDEX idx_osm_stack_merge ON rlarp.osm_stack ( @@ -82,6 +119,7 @@ BEGIN AND o.version IN ('Actual', 'Forecast', 'Quotes') AND o.part IS NOT NULL AND substring(o.glec, 1, 1) <= '2'; + -- 44 seconds ----------------------------------------------------------------------- @@ -141,6 +179,7 @@ BEGIN pltq = src.pltq, plevel = src.plevel, partgroup = src.partgroup; + -- 17 seconds ----------------------------------------------------------------------- -- Step 3: Apply target prices and embed target metadata @@ -165,113 +204,38 @@ BEGIN AND tp.chan = q.chan AND tp.tier = q.tier AND FLOOR(q.vol / NULLIF(q.pltq, 0))::int <@ tp.vol; + -- 20 seconds ----------------------------------------------------------------------- -- Step 4: Lookup price history and embed all relevant keys and precedence ----------------------------------------------------------------------- + -- Use the helper function to extract last price precedence and build JSON explanation as in single_price_call UPDATE pricequote.queue q SET - last_price = COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'price')::numeric, - (hist -> q.v1ds -> 'dss' ->> 'price')::numeric, - (hist -> 'mrq' ->> 'price')::numeric, - (hist -> 'mrs' ->> 'price')::numeric - ), - last_qty = COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'qty')::numeric, - (hist -> q.v1ds -> 'dss' ->> 'qty')::numeric, - (hist -> 'mrq' ->> 'qty')::numeric, - (hist -> 'mrs' ->> 'qty')::numeric - ), - last_dataseg = COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'datasegment'), - (hist -> q.v1ds -> 'dss' ->> 'datasegment'), - (hist -> 'mrq' ->> 'datasegment'), - (hist -> 'mrs' ->> 'datasegment') - ), - last_date = COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'odate')::date, - (hist -> q.v1ds -> 'dss' ->> 'odate')::date, - (hist -> 'mrq' ->> 'odate')::date, - (hist -> 'mrs' ->> 'odate')::date - ), - last_order = COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'ordnum'), - (hist -> q.v1ds -> 'dss' ->> 'ordnum'), - (hist -> 'mrq' ->> 'ordnum'), - (hist -> 'mrs' ->> 'ordnum') - ), - last_quote = COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'quoten'), - (hist -> q.v1ds -> 'dss' ->> 'quoten'), - (hist -> 'mrq' ->> 'quoten'), - (hist -> 'mrs' ->> 'quoten') - ), - last_source = CASE - WHEN (hist -> q.v1ds -> 'dsq' ->> 'price') IS NOT NULL THEN 'dsq' - WHEN (hist -> q.v1ds -> 'dss' ->> 'price') IS NOT NULL THEN 'dss' - WHEN (hist -> 'mrq' ->> 'price') IS NOT NULL THEN 'mrq' - WHEN (hist -> 'mrs' ->> 'price') IS NOT NULL THEN 'mrs' - ELSE NULL - END, + last_price = (last_json->>'price')::numeric, + last_qty = (last_json->>'qty')::numeric, + last_dataseg = last_json->>'datasegment', + last_date = (last_json->>'odate')::date, + last_order = last_json->>'ordnum', + last_quote = last_json->>'quoten', + last_source = last_json->>'source', expl = q.expl || jsonb_build_object( - 'last_price', COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'price')::numeric, - (hist -> q.v1ds -> 'dss' ->> 'price')::numeric, - (hist -> 'mrq' ->> 'price')::numeric, - (hist -> 'mrs' ->> 'price')::numeric - ), - 'last_qty', COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'qty')::numeric, - (hist -> q.v1ds -> 'dss' ->> 'qty')::numeric, - (hist -> 'mrq' ->> 'qty')::numeric, - (hist -> 'mrs' ->> 'qty')::numeric - ), - 'last_dataseg', COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'datasegment'), - (hist -> q.v1ds -> 'dss' ->> 'datasegment'), - (hist -> 'mrq' ->> 'datasegment'), - (hist -> 'mrs' ->> 'datasegment') - ), - 'last_source', CASE - WHEN (hist -> q.v1ds -> 'dsq' ->> 'price') IS NOT NULL THEN 'dsq' - WHEN (hist -> q.v1ds -> 'dss' ->> 'price') IS NOT NULL THEN 'dss' - WHEN (hist -> 'mrq' ->> 'price') IS NOT NULL THEN 'mrq' - WHEN (hist -> 'mrs' ->> 'price') IS NOT NULL THEN 'mrs' - ELSE NULL - END, - 'last_date', COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'odate')::date, - (hist -> q.v1ds -> 'dss' ->> 'odate')::date, - (hist -> 'mrq' ->> 'odate')::date, - (hist -> 'mrs' ->> 'odate')::date - ), - 'last_order', COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'ordnum'), - (hist -> q.v1ds -> 'dss' ->> 'ordnum'), - (hist -> 'mrq' ->> 'ordnum'), - (hist -> 'mrs' ->> 'ordnum') - ), - 'last_quote', COALESCE( - (hist -> q.v1ds -> 'dsq' ->> 'quoten'), - (hist -> q.v1ds -> 'dss' ->> 'quoten'), - (hist -> 'mrq' ->> 'quoten'), - (hist -> 'mrs' ->> 'quoten') - ), - 'mrs', hist -> 'mrs', - 'mrq', hist -> 'mrq', - 'lvs', hist -> 'lvs', - 'lvq', hist -> 'lvq', - 'dss', hist -> q.v1ds -> 'dss', - 'dsq', hist -> q.v1ds -> 'dsq' + 'last_price', (last_json->>'price')::numeric, + 'last_qty', (last_json->>'qty')::numeric, + 'last_dataseg', last_json->>'datasegment', + 'last_source', last_json->>'source', + 'last_date', (last_json->>'odate')::date, + 'last_order', last_json->>'ordnum', + 'last_quote', last_json->>'quoten' ) FROM ( - SELECT q.ctid, lp.part_stats AS hist + SELECT q.ctid, pricequote.pick_last_price_from_hist(lp.part_stats, q.v1ds) AS last_json FROM pricequote.queue q JOIN pricequote.lastpricedetail lp ON lp.customer = q.cust AND lp.partgroup = q.partgroup ) sub WHERE q.ctid = sub.ctid; + -- 2 minutes 36 seconds ----------------------------------------------------------------------- -- Step 5: Resolve best list price and insert it with list code @@ -305,6 +269,7 @@ BEGIN ) FROM best_price p WHERE q.ctid = p.ctid; + -- 15 seconds ----------------------------------------------------------------------- -- Step 6: Compute guidance price using logic function @@ -331,6 +296,7 @@ BEGIN ) g ON TRUE ) g WHERE q.ctid = g.ctid; + -- 27 seconds ----------------------------------------------------------------------- @@ -351,6 +317,7 @@ BEGIN AND o.version IN ('Actual', 'Forecast', 'Quotes') AND o.part IS NOT NULL AND substring(o.glec, 1, 1) <= '2'; + -- 6 minutes 31 seconds ----------------------------------------------------------------------- -- Done