books/backend/Books.Api/Database/Migrations/025_Orders.sql

93 lines
3.1 KiB
MySQL
Raw Normal View History

-- Migration: 025_Orders
-- Description: Create order_read_models table for order management
CREATE TABLE IF NOT EXISTS order_read_models (
-- EventFlow standard columns
aggregate_id TEXT PRIMARY KEY,
create_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
update_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
last_aggregate_sequence_number INTEGER NOT NULL DEFAULT 0,
-- Company and fiscal year
company_id TEXT NOT NULL,
fiscal_year_id TEXT NOT NULL,
-- Customer reference
customer_id TEXT NOT NULL,
customer_name TEXT NOT NULL,
customer_number TEXT NOT NULL,
-- Order identification
order_number TEXT NOT NULL,
order_date DATE,
expected_delivery_date DATE,
-- Status: draft, confirmed, partially_invoiced, fully_invoiced, cancelled
status TEXT NOT NULL DEFAULT 'draft',
-- Amounts (set when confirmed)
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,
-- Currency
currency TEXT NOT NULL DEFAULT 'DKK',
-- Lines (stored as JSON, includes invoicing status per line)
lines TEXT NOT NULL DEFAULT '[]',
-- Invoice reference (latest invoice created from this order)
invoice_id TEXT,
invoice_number TEXT,
-- Notes and reference
notes TEXT,
reference TEXT,
-- Status timestamps
confirmed_at TIMESTAMP WITH TIME ZONE,
confirmed_by TEXT,
invoiced_at TIMESTAMP WITH TIME ZONE,
invoiced_by TEXT,
cancelled_at TIMESTAMP WITH TIME ZONE,
cancelled_by TEXT,
cancelled_reason TEXT,
-- Audit
created_by TEXT NOT NULL,
updated_by TEXT
);
-- Indexes for common queries
CREATE INDEX IF NOT EXISTS idx_order_read_models_company_id
ON order_read_models(company_id);
CREATE INDEX IF NOT EXISTS idx_order_read_models_customer_id
ON order_read_models(customer_id);
CREATE INDEX IF NOT EXISTS idx_order_read_models_fiscal_year_id
ON order_read_models(fiscal_year_id);
CREATE INDEX IF NOT EXISTS idx_order_read_models_status
ON order_read_models(status);
CREATE INDEX IF NOT EXISTS idx_order_read_models_order_date
ON order_read_models(order_date DESC);
CREATE INDEX IF NOT EXISTS idx_order_read_models_invoice_id
ON order_read_models(invoice_id)
WHERE invoice_id IS NOT NULL;
-- Unique constraint for order number per company
CREATE UNIQUE INDEX IF NOT EXISTS idx_order_read_models_company_order_number
ON order_read_models(company_id, order_number);
-- Composite index for listing orders by company and status
CREATE INDEX IF NOT EXISTS idx_order_read_models_company_status_date
ON order_read_models(company_id, status, order_date DESC);
COMMENT ON TABLE order_read_models IS 'Read model for orders (Ordrer)';
COMMENT ON COLUMN order_read_models.order_number IS 'Order number format: ORD-YYYY-NNNN (Ordrenummer)';
COMMENT ON COLUMN order_read_models.status IS 'Order status: draft, confirmed, partially_invoiced, fully_invoiced, cancelled';
COMMENT ON COLUMN order_read_models.lines IS 'JSON array of order lines with invoicing status';