87 lines
3.5 KiB
MySQL
87 lines
3.5 KiB
MySQL
|
|
-- Migration: 012_Invoices.sql
|
||
|
|
-- Description: Invoice read model for invoicing system
|
||
|
|
-- Date: 2026-01-18
|
||
|
|
-- Phase: 2 of Invoicing Implementation
|
||
|
|
|
||
|
|
-- Invoice read model table
|
||
|
|
CREATE TABLE IF NOT EXISTS invoice_read_models (
|
||
|
|
-- EventFlow standard fields
|
||
|
|
aggregate_id VARCHAR(255) PRIMARY KEY,
|
||
|
|
last_aggregate_sequence_number BIGINT NOT NULL DEFAULT 0,
|
||
|
|
create_time TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||
|
|
update_time TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||
|
|
|
||
|
|
-- Company and fiscal year
|
||
|
|
company_id VARCHAR(255) NOT NULL,
|
||
|
|
fiscal_year_id VARCHAR(255),
|
||
|
|
|
||
|
|
-- Customer reference
|
||
|
|
customer_id VARCHAR(255) NOT NULL,
|
||
|
|
customer_name VARCHAR(255) NOT NULL,
|
||
|
|
customer_number VARCHAR(20) NOT NULL,
|
||
|
|
|
||
|
|
-- Invoice identification (Momsloven §52: Sequential per year)
|
||
|
|
invoice_number VARCHAR(50) NOT NULL,
|
||
|
|
invoice_date DATE,
|
||
|
|
due_date DATE,
|
||
|
|
|
||
|
|
-- Status: draft, sent, partially_paid, paid, voided
|
||
|
|
status VARCHAR(20) NOT NULL DEFAULT 'draft',
|
||
|
|
|
||
|
|
-- Amounts (calculated from lines)
|
||
|
|
amount_ex_vat DECIMAL(18, 2) NOT NULL DEFAULT 0,
|
||
|
|
amount_vat DECIMAL(18, 2) NOT NULL DEFAULT 0,
|
||
|
|
amount_total DECIMAL(18, 2) NOT NULL DEFAULT 0,
|
||
|
|
amount_paid DECIMAL(18, 2) NOT NULL DEFAULT 0,
|
||
|
|
amount_remaining DECIMAL(18, 2) NOT NULL DEFAULT 0,
|
||
|
|
|
||
|
|
-- Currency (default DKK)
|
||
|
|
currency VARCHAR(3) NOT NULL DEFAULT 'DKK',
|
||
|
|
|
||
|
|
-- VAT settings
|
||
|
|
vat_code VARCHAR(20),
|
||
|
|
|
||
|
|
-- Payment terms
|
||
|
|
payment_terms_days INT NOT NULL DEFAULT 30,
|
||
|
|
|
||
|
|
-- Invoice lines as JSONB for flexibility
|
||
|
|
-- Structure: [{ lineNumber, description, quantity, unitPrice, vatCode, amountExVat, amountVat, amountTotal, accountId }]
|
||
|
|
lines JSONB NOT NULL DEFAULT '[]',
|
||
|
|
|
||
|
|
-- Ledger integration
|
||
|
|
ledger_transaction_id VARCHAR(255),
|
||
|
|
|
||
|
|
-- Notes and reference
|
||
|
|
notes TEXT,
|
||
|
|
reference VARCHAR(255),
|
||
|
|
|
||
|
|
-- Timestamps for status changes
|
||
|
|
sent_at TIMESTAMP WITH TIME ZONE,
|
||
|
|
paid_at TIMESTAMP WITH TIME ZONE,
|
||
|
|
voided_at TIMESTAMP WITH TIME ZONE,
|
||
|
|
voided_reason TEXT,
|
||
|
|
voided_by VARCHAR(255),
|
||
|
|
|
||
|
|
-- Audit
|
||
|
|
created_by VARCHAR(255) NOT NULL,
|
||
|
|
updated_by VARCHAR(255)
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Indexes for common queries
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_invoice_company_id ON invoice_read_models(company_id);
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_invoice_customer_id ON invoice_read_models(customer_id);
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_invoice_status ON invoice_read_models(status);
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_invoice_fiscal_year_id ON invoice_read_models(fiscal_year_id);
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_invoice_number ON invoice_read_models(company_id, invoice_number);
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_invoice_date ON invoice_read_models(invoice_date);
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_invoice_due_date ON invoice_read_models(due_date);
|
||
|
|
|
||
|
|
-- Unique constraint on invoice number per company (Momsloven §52 compliance)
|
||
|
|
CREATE UNIQUE INDEX IF NOT EXISTS idx_invoice_number_unique ON invoice_read_models(company_id, invoice_number);
|
||
|
|
|
||
|
|
-- Comment explaining the table
|
||
|
|
COMMENT ON TABLE invoice_read_models IS 'Invoice read model for the Books accounting system. Supports B2B and B2C invoicing with Danish tax compliance (Momsloven §52).';
|
||
|
|
COMMENT ON COLUMN invoice_read_models.invoice_number IS 'Sequential invoice number per year, format: INV-YYYY-NNNN (Momsloven §52)';
|
||
|
|
COMMENT ON COLUMN invoice_read_models.lines IS 'Invoice lines as JSONB array with lineNumber, description, quantity, unitPrice, vatCode, amounts, accountId';
|
||
|
|
COMMENT ON COLUMN invoice_read_models.ledger_transaction_id IS 'Reference to the Ledger transaction when invoice is sent/posted';
|