85 lines
3.6 KiB
MySQL
85 lines
3.6 KiB
MySQL
|
|
-- 011_Customers.sql
|
||
|
|
-- Creates customer read model tables and number series for invoicing support
|
||
|
|
-- Supports B2B (business with CVR) and B2C (private) customers
|
||
|
|
-- Each customer gets a sub-ledger account under 1900 Debitorer
|
||
|
|
|
||
|
|
-- Customer read models
|
||
|
|
CREATE TABLE IF NOT EXISTS customer_read_models (
|
||
|
|
-- EventFlow standard columns
|
||
|
|
aggregate_id VARCHAR(255) PRIMARY KEY,
|
||
|
|
create_time TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
updated_time TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
last_aggregate_sequence_number INT NOT NULL DEFAULT 1,
|
||
|
|
|
||
|
|
-- Business columns (snake_case)
|
||
|
|
company_id VARCHAR(255) NOT NULL,
|
||
|
|
customer_number VARCHAR(20) NOT NULL,
|
||
|
|
customer_type VARCHAR(20) NOT NULL, -- 'Business' or 'Private'
|
||
|
|
name VARCHAR(255) NOT NULL,
|
||
|
|
cvr VARCHAR(8), -- Required for Business, optional for Private
|
||
|
|
address VARCHAR(500),
|
||
|
|
postal_code VARCHAR(10),
|
||
|
|
city VARCHAR(100),
|
||
|
|
country VARCHAR(2) NOT NULL DEFAULT 'DK',
|
||
|
|
email VARCHAR(255),
|
||
|
|
phone VARCHAR(50),
|
||
|
|
payment_terms_days INT NOT NULL DEFAULT 30,
|
||
|
|
default_revenue_account_id VARCHAR(255),
|
||
|
|
sub_ledger_account_id VARCHAR(255) NOT NULL, -- Auto-created 1900-XXXX account
|
||
|
|
is_active BOOLEAN NOT NULL DEFAULT TRUE,
|
||
|
|
|
||
|
|
CONSTRAINT fk_customer_company
|
||
|
|
FOREIGN KEY (company_id) REFERENCES company_read_models(aggregate_id) ON DELETE CASCADE,
|
||
|
|
CONSTRAINT chk_customer_type
|
||
|
|
CHECK (customer_type IN ('Business', 'Private')),
|
||
|
|
CONSTRAINT chk_payment_terms
|
||
|
|
CHECK (payment_terms_days >= 0 AND payment_terms_days <= 365)
|
||
|
|
);
|
||
|
|
|
||
|
|
-- Unique customer number per company
|
||
|
|
CREATE UNIQUE INDEX IF NOT EXISTS idx_customer_number
|
||
|
|
ON customer_read_models(company_id, customer_number);
|
||
|
|
|
||
|
|
-- Lookup by company
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_customer_company
|
||
|
|
ON customer_read_models(company_id);
|
||
|
|
|
||
|
|
-- Lookup by CVR (for B2B customers)
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_customer_cvr
|
||
|
|
ON customer_read_models(cvr) WHERE cvr IS NOT NULL;
|
||
|
|
|
||
|
|
-- Search by name
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_customer_name
|
||
|
|
ON customer_read_models(company_id, name);
|
||
|
|
|
||
|
|
-- Filter active customers
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_customer_active
|
||
|
|
ON customer_read_models(company_id, is_active) WHERE is_active = TRUE;
|
||
|
|
|
||
|
|
-- Number series for sequential numbering (customers, invoices, credit notes)
|
||
|
|
-- Uses atomic UPSERT for thread-safe number generation
|
||
|
|
CREATE TABLE IF NOT EXISTS number_series (
|
||
|
|
id SERIAL PRIMARY KEY,
|
||
|
|
company_id VARCHAR(255) NOT NULL,
|
||
|
|
sequence_key VARCHAR(100) NOT NULL, -- e.g., 'customer', 'invoice-2024', 'creditnote-2024'
|
||
|
|
last_number INT NOT NULL DEFAULT 0,
|
||
|
|
prefix VARCHAR(20), -- e.g., 'INV-2024-', 'CN-2024-', ''
|
||
|
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||
|
|
|
||
|
|
UNIQUE(company_id, sequence_key),
|
||
|
|
CONSTRAINT fk_number_series_company
|
||
|
|
FOREIGN KEY (company_id) REFERENCES company_read_models(aggregate_id) ON DELETE CASCADE
|
||
|
|
);
|
||
|
|
|
||
|
|
CREATE INDEX IF NOT EXISTS idx_number_series_company
|
||
|
|
ON number_series(company_id);
|
||
|
|
|
||
|
|
-- Comments for documentation
|
||
|
|
COMMENT ON TABLE customer_read_models IS 'Customer master data supporting B2B and B2C customers';
|
||
|
|
COMMENT ON COLUMN customer_read_models.customer_type IS 'Business (requires CVR) or Private (no CVR required)';
|
||
|
|
COMMENT ON COLUMN customer_read_models.sub_ledger_account_id IS 'Auto-created sub-ledger account (1900-XXXX) for customer receivables';
|
||
|
|
COMMENT ON COLUMN customer_read_models.payment_terms_days IS 'Default payment terms in days, used to calculate invoice due dates';
|
||
|
|
|
||
|
|
COMMENT ON TABLE number_series IS 'Sequential number generation for customers, invoices, and credit notes (Momsloven §52)';
|
||
|
|
COMMENT ON COLUMN number_series.sequence_key IS 'Identifies the sequence: customer, invoice-YYYY, creditnote-YYYY';
|