-- Backup original sell_cost values (just in case) -- Run this once: will add a column original_sell_cost and copy existing sell_cost into it ALTER TABLE IF EXISTS falukant_type.product ADD COLUMN IF NOT EXISTS original_sell_cost numeric; UPDATE falukant_type.product SET sell_cost = sell_cost * ((6 * 7 / 100) + 100); -- Compute min and max cumulative tax across all regions WITH RECURSIVE ancestors AS ( SELECT id AS start_id, id, parent_id, tax_percent FROM falukant_data.region UNION ALL SELECT a.start_id, r.id, r.parent_id, r.tax_percent FROM falukant_data.region r JOIN ancestors a ON r.id = a.parent_id ), totals AS ( SELECT start_id, COALESCE(SUM(tax_percent),0) AS total FROM ancestors GROUP BY start_id ), mm AS ( SELECT COALESCE(MIN(total),0) AS min_total, COALESCE(MAX(total),0) AS max_total FROM totals ) SELECT * FROM mm; -- Choose one of the following update blocks to run: -- 1) MIN-STRATEGY: increase sell_cost so that taxes at the minimal cumulative tax have no effect -- (this will set sell_cost = CEIL(original_sell_cost * (1 / (1 - min_total/100)))) -- BEGIN MIN-STRATEGY -- WITH mm AS ( -- WITH RECURSIVE ancestors AS ( -- SELECT id AS start_id, id, parent_id, tax_percent FROM falukant_data.region -- UNION ALL -- SELECT a.start_id, r.id, r.parent_id, r.tax_percent -- FROM falukant_data.region r -- JOIN ancestors a ON r.id = a.parent_id -- ), totals AS ( -- SELECT start_id, COALESCE(SUM(tax_percent),0) AS total FROM ancestors GROUP BY start_id -- ) -- SELECT COALESCE(MIN(total),0) AS min_total FROM totals -- ) -- UPDATE falukant_type.product -- SET sell_cost = CEIL(original_sell_cost * (CASE WHEN (1 - (SELECT min_total FROM mm)/100) <= 0 THEN 1 ELSE (1 / (1 - (SELECT min_total FROM mm)/100)) END)); -- END MIN-STRATEGY -- 2) MAX-STRATEGY: increase sell_cost so that taxes at the maximal cumulative tax have no effect -- (this will set sell_cost = CEIL(original_sell_cost * (1 / (1 - max_total/100)))) -- BEGIN MAX-STRATEGY -- WITH mm AS ( -- WITH RECURSIVE ancestors AS ( -- SELECT id AS start_id, id, parent_id, tax_percent FROM falukant_data.region -- UNION ALL -- SELECT a.start_id, r.id, r.parent_id, r.tax_percent -- FROM falukant_data.region r -- JOIN ancestors a ON r.id = a.parent_id -- ), totals AS ( -- SELECT start_id, COALESCE(SUM(tax_percent),0) AS total FROM ancestors GROUP BY start_id -- ) -- SELECT COALESCE(MAX(total),0) AS max_total FROM totals -- ) -- UPDATE falukant_type.product -- SET sell_cost = CEIL(original_sell_cost * (CASE WHEN (1 - (SELECT max_total FROM mm)/100) <= 0 THEN 1 ELSE (1 / (1 - (SELECT max_total FROM mm)/100)) END)); -- END MAX-STRATEGY -- Notes: -- 1) Uncomment exactly one strategy block (MIN or MAX) and run the script. -- 2) The script creates `original_sell_cost` as a backup; keep it for safety. -- 3) CEIL is used to avoid undercompensating due to rounding. If you prefer ROUND use ROUND(...). -- 4) Test on a staging DB first.