Files
calminer/scripts/migrations/000_base.sql
zwitschi 5b1322ddbc
Some checks failed
Run Tests / test (push) Failing after 1m51s
feat: Add application-level settings for CSS color management
- Introduced a new table `application_setting` to store configurable application options.
- Implemented functions to manage CSS color settings, including loading, updating, and reading environment overrides.
- Added a new settings view to render and manage theme colors.
- Updated UI to include a settings page with theme color management and environment overrides display.
- Enhanced CSS styles for the settings page and sidebar navigation.
- Created unit and end-to-end tests for the new settings functionality and CSS management.
2025-10-25 19:20:52 +02:00

162 lines
5.0 KiB
PL/PgSQL

-- Baseline migration for CalMiner database schema
-- Date: 2025-10-25
-- Purpose: Consolidate foundational tables and reference data
BEGIN;
-- Currency reference 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
);
INSERT INTO currency (code, name, symbol, is_active)
VALUES
('USD', 'United States Dollar', 'USD$', TRUE),
('EUR', 'Euro', 'EUR', TRUE),
('CLP', 'Chilean Peso', 'CLP$', TRUE),
('RMB', 'Chinese Yuan', 'RMB', TRUE),
('GBP', 'British Pound', 'GBP', TRUE),
('CAD', 'Canadian Dollar', 'CAD$', TRUE),
('AUD', 'Australian Dollar', 'AUD$', TRUE)
ON CONFLICT (code) DO UPDATE
SET name = EXCLUDED.name,
symbol = EXCLUDED.symbol,
is_active = EXCLUDED.is_active;
-- Application-level settings table
CREATE TABLE IF NOT EXISTS application_setting (
id SERIAL PRIMARY KEY,
key VARCHAR(128) NOT NULL UNIQUE,
value TEXT NOT NULL,
value_type VARCHAR(32) NOT NULL DEFAULT 'string',
category VARCHAR(32) NOT NULL DEFAULT 'general',
description TEXT,
is_editable BOOLEAN NOT NULL DEFAULT TRUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE UNIQUE INDEX IF NOT EXISTS ux_application_setting_key
ON application_setting (key);
CREATE INDEX IF NOT EXISTS ix_application_setting_category
ON application_setting (category);
-- Measurement unit reference table
CREATE TABLE IF NOT EXISTS measurement_unit (
id SERIAL PRIMARY KEY,
code VARCHAR(64) NOT NULL UNIQUE,
name VARCHAR(128) NOT NULL,
symbol VARCHAR(16),
unit_type VARCHAR(32) NOT NULL,
is_active BOOLEAN NOT NULL DEFAULT TRUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
INSERT INTO measurement_unit (code, name, symbol, unit_type, is_active)
VALUES
('tonnes', 'Tonnes', 't', 'mass', TRUE),
('kilograms', 'Kilograms', 'kg', 'mass', TRUE),
('pounds', 'Pounds', 'lb', 'mass', TRUE),
('liters', 'Liters', 'L', 'volume', TRUE),
('cubic_meters', 'Cubic Meters', 'm3', 'volume', TRUE),
('kilowatt_hours', 'Kilowatt Hours', 'kWh', 'energy', TRUE)
ON CONFLICT (code) DO UPDATE
SET name = EXCLUDED.name,
symbol = EXCLUDED.symbol,
unit_type = EXCLUDED.unit_type,
is_active = EXCLUDED.is_active;
-- Consumption and production measurement metadata
ALTER TABLE consumption
ADD COLUMN IF NOT EXISTS unit_name VARCHAR(64);
ALTER TABLE consumption
ADD COLUMN IF NOT EXISTS unit_symbol VARCHAR(16);
ALTER TABLE production_output
ADD COLUMN IF NOT EXISTS unit_name VARCHAR(64);
ALTER TABLE production_output
ADD COLUMN IF NOT EXISTS unit_symbol VARCHAR(16);
-- Currency integration for CAPEX and OPEX
ALTER TABLE capex
ADD COLUMN IF NOT EXISTS currency_id INTEGER;
ALTER TABLE opex
ADD COLUMN IF NOT EXISTS currency_id INTEGER;
DO $$
DECLARE
usd_id INTEGER;
BEGIN
-- Ensure currency_id columns align with legacy currency_code values when present
IF EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_name = 'capex' AND column_name = 'currency_code'
) THEN
UPDATE capex AS c
SET currency_id = cur.id
FROM currency AS cur
WHERE c.currency_code = cur.code
AND (c.currency_id IS DISTINCT FROM cur.id);
END IF;
IF EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_name = 'opex' AND column_name = 'currency_code'
) THEN
UPDATE opex AS o
SET currency_id = cur.id
FROM currency AS cur
WHERE o.currency_code = cur.code
AND (o.currency_id IS DISTINCT FROM cur.id);
END IF;
SELECT id INTO usd_id FROM currency WHERE code = 'USD';
IF usd_id IS NOT NULL THEN
UPDATE capex SET currency_id = usd_id WHERE currency_id IS NULL;
UPDATE opex SET currency_id = usd_id WHERE currency_id IS NULL;
END IF;
END $$;
ALTER TABLE capex
ALTER COLUMN currency_id SET NOT NULL;
ALTER TABLE opex
ALTER COLUMN currency_id SET NOT NULL;
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM information_schema.table_constraints
WHERE table_schema = current_schema()
AND table_name = 'capex'
AND constraint_name = 'fk_capex_currency'
) THEN
ALTER TABLE capex
ADD CONSTRAINT fk_capex_currency FOREIGN KEY (currency_id)
REFERENCES currency (id) ON DELETE RESTRICT;
END IF;
IF NOT EXISTS (
SELECT 1 FROM information_schema.table_constraints
WHERE table_schema = current_schema()
AND table_name = 'opex'
AND constraint_name = 'fk_opex_currency'
) THEN
ALTER TABLE opex
ADD CONSTRAINT fk_opex_currency FOREIGN KEY (currency_id)
REFERENCES currency (id) ON DELETE RESTRICT;
END IF;
END $$;
ALTER TABLE capex
DROP COLUMN IF EXISTS currency_code;
ALTER TABLE opex
DROP COLUMN IF EXISTS currency_code;
COMMIT;