Files
yourpart3/backend/migrations/20260101000002-add-neutral-sell-costs-to-product.cjs

51 lines
1.9 KiB
JavaScript

"use strict";
module.exports = {
async up(queryInterface, Sequelize) {
// 1) add backup column for original sell_cost (idempotent)
await queryInterface.sequelize.query(`
ALTER TABLE IF EXISTS falukant_type.product
ADD COLUMN IF NOT EXISTS original_sell_cost numeric;
`);
// 2) if original_sell_cost is not set, copy current sell_cost into it
await queryInterface.sequelize.query(`
UPDATE falukant_type.product
SET original_sell_cost = sell_cost
WHERE original_sell_cost IS NULL;
`);
// 3) compute max cumulative tax across regions and increase sell_cost accordingly
// We use the maximum cumulative tax (worst-case) so sellers are neutral across regions.
// Formula: neutral_sell = CEIL(original_sell_cost * (1 / (1 - max_total/100)))
await queryInterface.sequelize.query(`
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(MAX(total),0) AS max_total FROM totals
)
UPDATE falukant_type.product
SET sell_cost = CEIL(original_sell_cost * (CASE WHEN (1 - mm.max_total/100) <= 0 THEN 1 ELSE (1 / (1 - mm.max_total/100)) END))
FROM mm
WHERE original_sell_cost IS NOT NULL;
`);
},
async down(queryInterface, Sequelize) {
await queryInterface.sequelize.query(`
ALTER TABLE IF EXISTS falukant_type.product
DROP COLUMN IF EXISTS sell_cost_min_neutral;
`);
await queryInterface.sequelize.query(`
ALTER TABLE IF EXISTS falukant_type.product
DROP COLUMN IF EXISTS sell_cost_max_neutral;
`);
}
};