CREATE OR ALTER PROCEDURE pricing.rebuild_targets AS BEGIN SET NOCOUNT ON; SET XACT_ABORT ON; -- auto-rollback on most runtime errors BEGIN TRY --clear import table DELETE FROM pricing.import_target_prices; --load the import table INSERT INTO pricing.import_target_prices SELECT stlc, ds, chan, tier, vol, -- Extract lower bound: text between '[' and ',' TRY_CAST(SUBSTRING(vol, 2, CHARINDEX(',', vol) - 2) AS INT) AS lower_bound, -- Extract upper bound: text between ',' and ')' CASE WHEN RIGHT(vol, 2) = ',)' THEN NULL ELSE TRY_CAST(SUBSTRING(vol, CHARINDEX(',', vol) + 1, LEN(vol) - CHARINDEX(',', vol) - 1) AS INT) END AS upper_bound, price, 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; END TRY BEGIN CATCH IF XACT_STATE() <> 0 ROLLBACK TRAN; -- Rethrow original error 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 */