80 lines
2.6 KiB
PL/PgSQL
80 lines
2.6 KiB
PL/PgSQL
-- Migration: Update invoices for pay period support and snapshot amounts
|
|
-- Invoices now cover a date range and store revenue/project amounts at time of addition
|
|
|
|
-- 1. Alter invoices table: date → start_date/end_date
|
|
ALTER TABLE invoices
|
|
ADD COLUMN start_date DATE,
|
|
ADD COLUMN end_date DATE;
|
|
|
|
-- Migrate existing data (use date as both start and end)
|
|
UPDATE invoices SET start_date = date, end_date = date WHERE start_date IS NULL;
|
|
|
|
-- Make date columns required
|
|
ALTER TABLE invoices
|
|
ALTER COLUMN start_date SET NOT NULL,
|
|
ALTER COLUMN end_date SET NOT NULL;
|
|
|
|
-- Drop old column
|
|
ALTER TABLE invoices DROP COLUMN date;
|
|
|
|
-- Add check: end_date >= start_date
|
|
ALTER TABLE invoices ADD CONSTRAINT invoices_date_range_check
|
|
CHECK (end_date >= start_date);
|
|
|
|
-- Index for querying by period
|
|
CREATE INDEX idx_invoices_period ON invoices(start_date, end_date);
|
|
|
|
-- 2. Add amount snapshot to invoice_revenues
|
|
-- This stores the revenue amount at time of addition (immutable for billing)
|
|
ALTER TABLE invoice_revenues
|
|
ADD COLUMN amount NUMERIC(10,2) NOT NULL DEFAULT 0.00;
|
|
|
|
-- Remove default after adding
|
|
ALTER TABLE invoice_revenues ALTER COLUMN amount DROP DEFAULT;
|
|
|
|
-- 3. Add amount snapshot to invoice_projects
|
|
ALTER TABLE invoice_projects
|
|
ADD COLUMN amount NUMERIC(10,2) NOT NULL DEFAULT 0.00;
|
|
|
|
ALTER TABLE invoice_projects ALTER COLUMN amount DROP DEFAULT;
|
|
|
|
-- 4. Add global uniqueness constraint for revenues
|
|
-- A revenue can only be on ONE invoice ever
|
|
CREATE OR REPLACE FUNCTION check_invoice_revenue_unique()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF EXISTS (
|
|
SELECT 1 FROM invoice_revenues
|
|
WHERE revenue_id = NEW.revenue_id
|
|
AND id IS DISTINCT FROM NEW.id
|
|
) THEN
|
|
RAISE EXCEPTION 'Revenue % is already on another invoice', NEW.revenue_id;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trg_invoice_revenue_unique
|
|
BEFORE INSERT OR UPDATE ON invoice_revenues
|
|
FOR EACH ROW EXECUTE FUNCTION check_invoice_revenue_unique();
|
|
|
|
-- 5. Add global uniqueness constraint for projects
|
|
-- A project can only be on ONE invoice ever
|
|
CREATE OR REPLACE FUNCTION check_invoice_project_unique()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF EXISTS (
|
|
SELECT 1 FROM invoice_projects
|
|
WHERE project_id = NEW.project_id
|
|
AND id IS DISTINCT FROM NEW.id
|
|
) THEN
|
|
RAISE EXCEPTION 'Project % is already on another invoice', NEW.project_id;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trg_invoice_project_unique
|
|
BEFORE INSERT OR UPDATE ON invoice_projects
|
|
FOR EACH ROW EXECUTE FUNCTION check_invoice_project_unique();
|