create an import table and avoid wrapping the initial import in a transaction for midday target updates that will run faster
This commit is contained in:
parent
d738bd8a98
commit
00b9d014c8
@ -5,12 +5,13 @@ BEGIN
|
|||||||
SET XACT_ABORT ON; -- auto-rollback on most runtime errors
|
SET XACT_ABORT ON; -- auto-rollback on most runtime errors
|
||||||
|
|
||||||
BEGIN TRY
|
BEGIN TRY
|
||||||
BEGIN TRAN;
|
|
||||||
|
--clear import table
|
||||||
DELETE FROM pricing.target_prices;
|
DELETE FROM pricing.import_target_prices;
|
||||||
|
|
||||||
INSERT INTO
|
--load the import table
|
||||||
pricing.target_prices
|
INSERT INTO
|
||||||
|
pricing.import_target_prices
|
||||||
SELECT
|
SELECT
|
||||||
stlc,
|
stlc,
|
||||||
ds,
|
ds,
|
||||||
@ -28,6 +29,19 @@ BEGIN
|
|||||||
math
|
math
|
||||||
FROM
|
FROM
|
||||||
usmidsap02.ubm.pricequote.target_prices_view;
|
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;
|
COMMIT TRAN;
|
||||||
|
|
||||||
@ -40,3 +54,64 @@ BEGIN
|
|||||||
THROW;
|
THROW;
|
||||||
END CATCH;
|
END CATCH;
|
||||||
END
|
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
|
||||||
|
*/
|
@ -17,3 +17,15 @@ ADD CONSTRAINT uq_target_prices_unique_combo
|
|||||||
UNIQUE (stlc, ds, chan, tier, vol, lower_bound);
|
UNIQUE (stlc, ds, chan, tier, vol, lower_bound);
|
||||||
|
|
||||||
--SELECT COUNT(*) FROM pricing.target_prices
|
--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
|
||||||
|
);
|
||||||
|
Loading…
Reference in New Issue
Block a user