This commit is contained in:
Paul Trowbridge 2025-08-08 02:59:42 -04:00
parent f8c62e5d27
commit 849d176ad0
2 changed files with 73 additions and 40 deletions

View File

@ -3,7 +3,7 @@ EXEC pricing.single_price_call
@bill = 'GRIF0001',
@ship = 'GRIF0001',
@part = 'XNS0T1G3G18B096',
@v1ds = 'v1:B..PLT..',
@v1ds = 'v1:B.L.PLT..',
@vol = 9600;

View File

@ -1,37 +1,73 @@
/*
====================================================================================
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
Purpose:
Single price call logic for SQL Server, designed to process a single scenario
(bill-to, ship-to, part, volume, and target data segment) and return enriched
pricing guidance along with explanation JSON for UI or API use.
-----------------------------------------------------------------------------------
Core Workflow:
1. **Seed Input**: Initialize queue with bill, ship, part, v1ds, vol.
2. **Customer & Channel Enrichment**:
- Resolve customer, channel, tier, pack quantity, price level.
- Classify and flag customized part scenarios when v1ds differs from part's own v1ds.
- Capture standard costs (current/future) and derive v0ds from v1ds.
3. **Last Price History**:
- Pull `part_stats` JSON from `pricing.lastpricedetail`.
- Extract most recent sale/quote via `pricing.pick_last_price_from_hist_json`.
- Flag part/dataseg mismatches (`last_isdiff`) and derive last v0ds.
4. **Target Price Application**:
- Lookup current and last target prices (matching respective v1ds).
- Store target price math JSON and pallet volume range.
5. **Cost Substitution & Normalization**:
- For customized or differing dataseg, substitute average costs from v1/v0 sources.
- Compute premiums and normalize last prices for comparison.
- Record calculation method (`Target Price Ratio` or `Cost Ratio`).
6. **List Price Selection**:
- From external `pricelist_ranged`, pick lowest valid list price in volume band.
- Nullify list price when customized, with relevance flag.
7. **Guidance Logic**:
- Pass target, normalized last, and list prices into `pricing.guidance_logic`.
- Return computed guidance price and rationale.
8. **JSON Explanation Build**:
- Assemble all pricing components into `expl` JSON for structured storage.
9. **UI JSON Build**:
- Package human-readable panels (History, List, Target Support, Guidance)
plus raw `expl` JSON into `ui_json`.
-----------------------------------------------------------------------------------
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
- @bill, @ship, @part, @v1ds, @vol
Reference Tables:
- pricing.target_prices
- pricing.lastpricedetail
- pricing.pricelist_ranged
- rlarp.cust
- CMS.CUSLG.itemm
- CMS.CUSLG.IPRCBHC
- rlarp.cost_v1ds / cost_v0ds
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
- Single row with:
* Enriched pricing attributes
* Target, last, list, and guidance prices
* Cost data and premiums
* `expl` JSON (raw detail)
* `ui_json` JSON (UI-ready panels)
Dependencies:
- pricing.guidance_logic (function)
- pricing.pick_last_price_from_hist_json (function)
- pricing.guidance_logic()
- pricing.pick_last_price_from_hist_json()
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
- Designed for single-row queries; see matrix_guidance.pg.sql for batch mode.
- Last price normalization ensures cross-segment comparisons are cost/target aligned.
- List price is ignored for customized part scenarios.
- Sequencing ensures:
* Historical context (last price) is established before guidance logic
* Target price and cost adjustments precede list price selection
====================================================================================
*/
CREATE OR ALTER PROCEDURE pricing.single_price_call
@ -95,13 +131,13 @@ BEGIN
);
--------------------------------------------------------------------------------
-- Step 1: Seed the queue with input row
-- Step 1: Seed input
--------------------------------------------------------------------------------
INSERT INTO @queue (bill, ship, part, v1ds, vol, expl)
VALUES (@bill, @ship, @part, @v1ds, @vol, '{}');
--------------------------------------------------------------------------------
-- Step 2: Enrich with channel, tier, customer, pack quantity, and price level
-- Step 2: Look up master data & costs
--------------------------------------------------------------------------------
UPDATE q
SET
@ -155,7 +191,7 @@ BEGIN
--------------------------------------------------------------------------------
-- Step 4: Pull last sale data and embed in columns and JSON
-- Step 3: Lookup Last Price
--------------------------------------------------------------------------------
UPDATE q
SET
@ -186,7 +222,7 @@ BEGIN
) b;
--------------------------------------------------------------------------------
-- Step 3: Apply target price and embed metadata as JSON
-- Step 4: Lookup Target Price
--------------------------------------------------------------------------------
UPDATE q
@ -216,10 +252,10 @@ BEGIN
);
--------------------------------------------------------------------------------
-- Step 3.b: Apply secondary cost data
-- Step 5: Normalize last price if different from target product
--------------------------------------------------------------------------------
-- goal datasegment will inherit original but if it is customerd, will pull available average
-- Goal data segment inherits part's original segment; if customized, pull available v1/v0 averages.
UPDATE q
SET
curstd = CASE WHEN customized = '' THEN q.curstd_orig ELSE COALESCE(v1.curstdus, v0.curstdus) END
@ -279,7 +315,7 @@ BEGIN
FROM @queue q;
--------------------------------------------------------------------------------
-- Step 5: Add list price info from external pricelist
-- Step 6: Lookup List Price
--------------------------------------------------------------------------------
WITH ranked_prices AS (
SELECT
@ -318,7 +354,7 @@ BEGIN
--------------------------------------------------------------------------------
-- Step 6: Compute guidance price and logic, and embed in JSON
-- Step 7: Compute guidance logic from target, normalized last, list price, and last date.
--------------------------------------------------------------------------------
UPDATE q
SET
@ -333,7 +369,7 @@ BEGIN
) g;
--------------------------------------------------------------------------------
-- Step 4b.2: Build JSON explanation object from populated columns
-- Step 8: Assemble structured 'expl' JSON from populated columns.
--------------------------------------------------------------------------------
UPDATE q
SET expl = (
@ -377,7 +413,7 @@ BEGIN
FROM @queue q;
--------------------------------------------------------------------------------
-- Step 7: Clean up for UI
-- Step 9: Create 'ui_json' with panels (History, List, Target Support, Guidance) and include raw 'expl' JSON.
--------------------------------------------------------------------------------
UPDATE q
SET ui_json = (
@ -458,11 +494,8 @@ BEGIN
)
FROM @queue q;
--------------------------------------------------------------------------------
-- Final: Return the enriched result row
-- Final: Return all calculated fields and JSON payloads.
--------------------------------------------------------------------------------
--SELECT guidance_price, hist, expl, ui_json FROM @queue;
SELECT * FROM @queue;
END;
SELECT * FROM @queue;
END;