67 lines
2.5 KiB
PL/PgSQL
67 lines
2.5 KiB
PL/PgSQL
-- Migration: create currency referential table and convert capex/opex to FK
|
|
-- Date: 2025-10-22
|
|
|
|
BEGIN;
|
|
|
|
-- 1) Create currency table
|
|
CREATE TABLE IF NOT EXISTS currency (
|
|
id SERIAL PRIMARY KEY,
|
|
code VARCHAR(3) NOT NULL UNIQUE,
|
|
name VARCHAR(128) NOT NULL,
|
|
symbol VARCHAR(8),
|
|
is_active BOOLEAN NOT NULL DEFAULT TRUE
|
|
);
|
|
|
|
-- 2) Seed some common currencies (idempotent)
|
|
INSERT INTO currency (code, name, symbol, is_active)
|
|
SELECT * FROM (VALUES
|
|
('USD','United States Dollar','$',TRUE),
|
|
('EUR','Euro','€',TRUE),
|
|
('CLP','Chilean Peso','CLP$',TRUE),
|
|
('RMB','Chinese Yuan','¥',TRUE),
|
|
('GBP','British Pound','£',TRUE),
|
|
('CAD','Canadian Dollar','C$',TRUE),
|
|
('AUD','Australian Dollar','A$',TRUE)
|
|
) AS v(code,name,symbol,is_active)
|
|
ON CONFLICT (code) DO NOTHING;
|
|
|
|
-- 3) Add currency_id columns to capex and opex with nullable true to allow backfill
|
|
ALTER TABLE capex ADD COLUMN IF NOT EXISTS currency_id INTEGER;
|
|
ALTER TABLE opex ADD COLUMN IF NOT EXISTS currency_id INTEGER;
|
|
|
|
-- 4) Backfill currency_id using existing currency_code column where present
|
|
-- Only do this if the currency_code column exists
|
|
DO $$
|
|
BEGIN
|
|
IF EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name='capex' AND column_name='currency_code') THEN
|
|
UPDATE capex SET currency_id = (
|
|
SELECT id FROM currency WHERE code = capex.currency_code LIMIT 1
|
|
);
|
|
END IF;
|
|
|
|
IF EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name='opex' AND column_name='currency_code') THEN
|
|
UPDATE opex SET currency_id = (
|
|
SELECT id FROM currency WHERE code = opex.currency_code LIMIT 1
|
|
);
|
|
END IF;
|
|
END$$;
|
|
|
|
-- 5) Make currency_id non-nullable and add FK constraint, default to USD where missing
|
|
UPDATE currency SET is_active = TRUE WHERE code = 'USD';
|
|
|
|
-- Ensure any NULL currency_id uses USD
|
|
UPDATE capex SET currency_id = (SELECT id FROM currency WHERE code='USD') WHERE currency_id IS NULL;
|
|
UPDATE opex SET currency_id = (SELECT id FROM currency WHERE code='USD') WHERE currency_id IS NULL;
|
|
|
|
ALTER TABLE capex ALTER COLUMN currency_id SET NOT NULL;
|
|
ALTER TABLE opex ALTER COLUMN currency_id SET NOT NULL;
|
|
|
|
ALTER TABLE capex ADD CONSTRAINT fk_capex_currency FOREIGN KEY (currency_id) REFERENCES currency(id);
|
|
ALTER TABLE opex ADD CONSTRAINT fk_opex_currency FOREIGN KEY (currency_id) REFERENCES currency(id);
|
|
|
|
-- 6) Optionally drop old currency_code columns if they exist
|
|
ALTER TABLE capex DROP COLUMN IF EXISTS currency_code;
|
|
ALTER TABLE opex DROP COLUMN IF EXISTS currency_code;
|
|
|
|
COMMIT;
|