Compare commits

...

4 Commits

8 changed files with 269 additions and 17 deletions

View File

@ -0,0 +1,139 @@
CREATE OR ALTER FUNCTION pricing.build_pricing_path_base
(
@_json NVARCHAR(MAX)
)
RETURNS @Result TABLE
(
stlc NVARCHAR(255),
seq BIGINT,
srtcode NVARCHAR(50),
ds NVARCHAR(255),
chan NVARCHAR(255),
tier NVARCHAR(255),
vol_lower INT,
vol_upper INT,
func NVARCHAR(50),
val DECIMAL(18,5),
price DECIMAL(18,5),
math NVARCHAR(MAX),
lastflag BIT
)
AS
BEGIN
WITH
-- 1⃣ Parse JSON into rows of (entity, attr, val)
parsed AS (
SELECT
entity = JSON_VALUE(j.value, '$.entity'),
attr = ISNULL(JSON_VALUE(j.value, '$.attr'), ''),
val = JSON_VALUE(j.value, '$.val'),
func = JSON_VALUE(j.value, '$.func')
FROM OPENJSON(@_json) j
),
-- 2⃣ Attach sequence & func from master option_sequence table
sequenced AS (
SELECT
p.entity,
p.attr,
p.val,
p.func,
s.DOMAIN,
DENSE_RANK() OVER (ORDER BY s.seq) AS seq,
ROW_NUMBER() OVER (PARTITION BY p.entity ORDER BY ISNULL(CAST(p.val AS DECIMAL(18,5)), 0) ASC) srt
FROM parsed p
JOIN pricing.option_sequence s
ON p.entity = s.entity
),
-- 3⃣ Recursively accumulate pricing path
combos AS (
-- 🚀 Base case: first in sequence
SELECT
s.entity,
s.attr,
s.seq,
srtcode = FORMAT(s.srt, '000'),
ds = CAST('' AS NVARCHAR(255)),
chan = CAST('' AS NVARCHAR(255)),
tier = CAST('' AS NVARCHAR(255)),
vol = CAST(NULL AS NVARCHAR(50)),
s.func,
val = CAST(s.val AS DECIMAL(18,5)),
agg = CAST(s.val AS DECIMAL(18,5)),
base = CASE WHEN s.func = 'Price' THEN CAST(s.val AS DECIMAL(18,5)) ELSE NULL END,
math = CAST(
'[' +
CASE
WHEN s.func = 'Price' THEN
CONCAT('"', RIGHT(REPLICATE(' ', 17) + (s.entity + ':' + s.attr), 17), ' + ', FORMAT(CAST(s.val AS DECIMAL(18,5)), '0.00000'), '"')
WHEN s.func = 'Factor' THEN
CONCAT('"', RIGHT(REPLICATE(' ', 17) + (s.entity + ':' + s.attr), 17), ' + ', FORMAT(ISNULL(CASE WHEN s.func = 'Price' THEN CAST(s.val AS DECIMAL(18,5)) END, 0) * (CAST(s.val AS DECIMAL(18,5)) - 1), '0.00000'), '"')
ELSE
CONCAT('"', RIGHT(REPLICATE(' ', 17) + (s.entity + ':' + s.attr), 17), ' ', FORMAT(CAST(s.val AS DECIMAL(18,5)), '0.00000'), '"')
END + ']'
AS NVARCHAR(MAX))
FROM sequenced s
WHERE s.seq = (SELECT MIN(x.seq) FROM sequenced x)
UNION ALL
-- 🔁 Recursive step: process next in sequence
SELECT
c.entity,
c.attr,
o.seq,
srtcode = c.srtcode + '.' + FORMAT(o.srt, '000'),
ds = CAST(c.ds + CASE WHEN o.DOMAIN = 'Product' THEN '.' + ISNULL(o.attr, '') ELSE '' END AS NVARCHAR(255)),
chan = CAST(CASE WHEN o.DOMAIN = 'Channel' THEN ISNULL(o.attr, '') ELSE c.chan END AS NVARCHAR(255)),
tier = CAST(CASE WHEN o.DOMAIN = 'Tier' THEN ISNULL(o.attr, '') ELSE c.tier END AS NVARCHAR(255)),
vol = CAST(CASE WHEN o.DOMAIN = 'Volume' THEN o.attr ELSE c.vol END AS NVARCHAR(50)),
o.func,
val = CAST(o.val AS DECIMAL(18,5)),
agg = CAST(CASE
WHEN o.func = 'Price' THEN c.agg + CAST(o.val AS DECIMAL(18,5))
WHEN o.func = 'Factor' THEN c.agg + ISNULL(c.base, 0) * (CAST(o.val AS DECIMAL(18,5)) - 1)
END AS DECIMAL(18,5)),
base = ISNULL(c.base, CASE WHEN o.func = 'Price' THEN CAST(o.val AS DECIMAL(18,5)) ELSE NULL END),
math = CAST(
CASE
WHEN (o.func = 'Price' AND CAST(o.val AS DECIMAL(18,5)) <> 0) OR (o.func = 'Factor' AND CAST(o.val AS DECIMAL(18,5)) <> 1) THEN
LEFT(c.math, LEN(c.math) - 1) + ',' +
CASE
WHEN o.func = 'Price' THEN
CONCAT('"', RIGHT(REPLICATE(' ', 17) + (o.entity + ':' + o.attr), 17), ' + ', FORMAT(CAST(o.val AS DECIMAL(18,5)), '0.00000'), '"')
WHEN o.func = 'Factor' THEN
CONCAT('"', RIGHT(REPLICATE(' ', 17) + (o.entity + ':' + o.attr), 17), ' + ', FORMAT(ISNULL(c.base, 0) * (CAST(o.val AS DECIMAL(18,5)) - 1), '0.00000'), '"')
ELSE
CONCAT('"', RIGHT(REPLICATE(' ', 17) + (o.entity + ':' + o.attr), 17), ' ', FORMAT(CAST(o.val AS DECIMAL(18,5)), '0.00000'), '"')
END + ']'
ELSE
c.math
END AS NVARCHAR(MAX))
FROM combos c
JOIN sequenced o
ON o.seq = c.seq + 1
)
INSERT INTO @Result
SELECT
stlc = c.attr,
c.seq,
c.srtcode,
ds = 'v1:' + SUBSTRING(c.ds, 2, 100),
c.chan,
c.tier,
vol_lower = CASE
WHEN c.vol LIKE '[0-9]%-[0-9]%' THEN CAST(LEFT(c.vol, CHARINDEX('-', c.vol) - 1) AS INT)
WHEN c.vol LIKE '[0-9]%' THEN CAST(c.vol AS INT)
ELSE NULL
END,
vol_upper = CASE
WHEN c.vol LIKE '[0-9]%-[0-9]%' THEN CAST(SUBSTRING(c.vol, CHARINDEX('-', c.vol) + 1, LEN(c.vol)) AS INT)
ELSE NULL
END,
c.func,
c.val,
c.agg,
math = c.math,
lastflag = CASE WHEN c.seq = (SELECT MAX(x.seq) FROM sequenced x) THEN 1 ELSE 0 END
FROM combos c
ORDER BY c.srtcode ASC;
RETURN;
END;

View File

@ -67,11 +67,11 @@ sequenced AS (
ARRAY[
CASE
WHEN s.func = 'Price' THEN
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' + ' || LPAD(to_char(s.val, 'FM9999999990.00000'), 10, ' ')
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' + ' || LPAD(to_char(s.val, 'FM9999999990.00000'), 10, ' ') || ' ' || CASE WHEN s.entity = 'Anchor' THEN 'Base Price' ELSE s.entity END
WHEN s.func = 'Factor' THEN
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' + ' || LPAD(to_char(COALESCE(NULLIF(CASE WHEN s.func = 'Price' THEN s.val END, NULL), 0) * (s.val - 1), 'FM9999999990.00000'), 10, ' ')
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' + ' || LPAD(to_char(COALESCE(NULLIF(CASE WHEN s.func = 'Price' THEN s.val END, NULL), 0) * (s.val - 1), 'FM9999999990.00000'), 10, ' ') || ' ' || s.entity
ELSE
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' ' || LPAD(to_char(s.val, 'FM9999999990.00000'), 10, ' ')
RPAD(s.entity || ':' || s.attr, 17, ' ') || ' ' || LPAD(to_char(s.val, 'FM9999999990.00000'), 10, ' ') || ' ' || s.entity
END
] math
FROM
@ -101,11 +101,11 @@ sequenced AS (
ARRAY[
CASE
WHEN o.func = 'Price' THEN
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' + ' || LPAD(to_char(o.val, 'FM9999999990.00000'), 10, ' ')
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' + ' || LPAD(to_char(o.val, 'FM9999999990.00000'), 10, ' ') || ' Fixed Charge' --|| to_char(o.val,'$FM90.000')
WHEN o.func = 'Factor' THEN
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' + ' || LPAD(to_char(COALESCE(c.base, 0) * (o.val - 1), 'FM9999999990.00000'), 10, ' ')
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' + ' || LPAD(to_char(COALESCE(c.base, 0) * (o.val - 1), 'FM9999999990.00000'), 10, ' ') || ' ' || to_char((o.val -1)*100,'FM990.09%')
ELSE
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' ' || LPAD(to_char(o.val, 'FM9999999990.00000'), 10, ' ')
RPAD(o.entity || ':' || o.attr, 17, ' ') || ' ' || LPAD(to_char(o.val, 'FM9999999990.00000'), 10, ' ') || ' Price Adder: ' || o.val
END
]
ELSE

View File

@ -494,11 +494,7 @@ BEGIN
ELSE '' END AS type,
----------------------note-------------------------------------------------
CASE WHEN value <> '' THEN
CASE WHEN CHARINDEX('Anchor',value) <> 0 THEN
'Base Floor'
ELSE
CASE SUBSTRING(value,19,1) WHEN '+' THEN 'Price' ELSE 'Premium' END
END
SUBSTRING(value,32,12)
ELSE '' END AS note
FROM @queue q
OUTER APPLY OPENJSON(q.expl, '$.target_math')

View File

@ -5,12 +5,13 @@ BEGIN
SET XACT_ABORT ON; -- auto-rollback on most runtime errors
BEGIN TRY
BEGIN TRAN;
DELETE FROM pricing.target_prices;
INSERT INTO
pricing.target_prices
--clear import table
DELETE FROM pricing.import_target_prices;
--load the import table
INSERT INTO
pricing.import_target_prices
SELECT
stlc,
ds,
@ -28,6 +29,19 @@ BEGIN
math
FROM
usmidsap02.ubm.pricequote.target_prices_view;
BEGIN TRAN;
--clear out destination inside transaction
DELETE FROM pricing.target_prices;
--insert new targets inside transaction
INSERT INTO
pricing.target_prices
SELECT
*
FROM
pricing.import_target_prices;
COMMIT TRAN;
@ -40,3 +54,64 @@ BEGIN
THROW;
END CATCH;
END
/*
WITH
allr AS (
SELECT
ct.compset
,ct.stlc
,ct.floor
,p.ds
,p.chan
,p.tier
,p.vol_lower
,p.vol_upper
,p.func
,p.val
,p.price
,p.math
FROM pricing.core_target ct
OUTER APPLY pricing.build_pricing_path_base(
-- Append JSON object to existing JSON array
CASE
WHEN ct.options IS NOT NULL AND RIGHT(LTRIM(RTRIM(ct.options)), 1) = ']'
THEN STUFF(
ct.options,
LEN(ct.options),
0,
CONCAT(',{"entity":"Anchor","attr":"', ct.stlc, '","val":', ct.floor, ',"func":"Price"}')
)
ELSE '[{"entity":"Anchor","attr":"' + ct.stlc + '","val":' + CAST(ct.floor AS NVARCHAR) + ',"func":"Price"}]'
END
) AS p
WHERE
1=1
-- AND ct.stlc = 'XNS0T1G3'
AND p.lastflag = 1
)
SELECT COUNT(*) FROM allr
--SELECT count(*) FROM pricing.pricing.core_target ct
OPTION (MAXRECURSION 500)
*/
/*
SELECT
c.compset,
c.stlc,
c.floor,
b.ds,
b.chan,
b.tier,
b.vol,
b.val,
b.price,
b.math AS math
FROM pricequote.core_target c
LEFT JOIN LATERAL pricequote.build_pricing_path_base(
c.options || jsonb_build_object('entity','Anchor','attr',c.stlc,'val',c.floor,'func','Price')
) AS b
ON b.lastflag
SELECT * FROM pricequote.option_sequence os
*/

16
tables/core_target.ms.sql Normal file
View File

@ -0,0 +1,16 @@
DROP TABLE IF EXISTS pricing.pricing.core_target;
CREATE TABLE pricing.pricing.core_target (
compset VARCHAR(MAX) NOT NULL,
stlc VARCHAR(30) NOT NULL,
floor NUMERIC(20,5) NOT NULL,
options VARCHAR(MAX) NOT NULL,
PRIMARY KEY (stlc)
);
CREATE SCHEMA import;
DROP TABLE IF EXISTS pricing.import.core_target;
-- CREATE TABLE pricing.import.core_target AS (SELECT * FROM pricing.pricing.core_target);
SELECT * INTO pricing.import.core_target FROM pricing.pricing.core_target;

View File

@ -0,0 +1,7 @@
CREATE TABLE pricing.pricing.option_sequence (
entity varchar(30) NOT NULL,
seq int NOT NULL,
func varchar(30) NOT NULL,
"domain" varchar(30) NOT NULL,
CONSTRAINT option_sequence_pkey PRIMARY KEY (entity)
);

View File

@ -0,0 +1,7 @@
CREATE TABLE option_sequence (
entity text NOT NULL,
seq int4 NOT NULL,
func text NOT NULL,
"domain" text NOT NULL,
CONSTRAINT option_sequence_pkey PRIMARY KEY (entity)
);

View File

@ -17,3 +17,15 @@ ADD CONSTRAINT uq_target_prices_unique_combo
UNIQUE (stlc, ds, chan, tier, vol, lower_bound);
--SELECT COUNT(*) FROM pricing.target_prices
CREATE TABLE pricing.import_target_prices (
stlc nvarchar(8) NOT NULL,
ds nvarchar(20) NOT NULL,
chan nvarchar(3) NOT NULL,
tier nvarchar(1) NOT NULL,
vol nvarchar(20) NOT NULL,
lower_bound int NOT NULL,
upper_bound int NULL,
price numeric(28,6) NOT NULL,
math nvarchar(MAX) NULL
);