Backend (.NET 10): - EventFlow CQRS/Event Sourcing with PostgreSQL - GraphQL.NET API with mutations and queries - Custom ReadModelSqlGenerator for snake_case PostgreSQL columns - Hangfire for background job processing - Integration tests with isolated test databases Frontend (React/Vite): - Initial project structure 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
110 lines
4.3 KiB
SQL
110 lines
4.3 KiB
SQL
-- 001_Initial.sql
|
|
-- Creates read model tables for Books API
|
|
-- NOTE: Column names use snake_case (PostgreSQL convention)
|
|
-- Custom ReadModelSqlGenerator converts C# PascalCase to snake_case
|
|
|
|
-- Company read models
|
|
CREATE TABLE IF NOT EXISTS company_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)
|
|
name VARCHAR(255) NOT NULL,
|
|
cvr VARCHAR(8),
|
|
address VARCHAR(500),
|
|
postal_code VARCHAR(10),
|
|
city VARCHAR(100),
|
|
country VARCHAR(2) NOT NULL DEFAULT 'DK',
|
|
fiscal_year_start_month SMALLINT NOT NULL DEFAULT 1,
|
|
currency VARCHAR(3) NOT NULL DEFAULT 'DKK',
|
|
vat_registered BOOLEAN NOT NULL DEFAULT FALSE,
|
|
vat_period_frequency VARCHAR(20)
|
|
);
|
|
|
|
CREATE UNIQUE INDEX IF NOT EXISTS idx_company_cvr ON company_read_models(cvr) WHERE cvr IS NOT NULL;
|
|
|
|
-- Fiscal year read models
|
|
CREATE TABLE IF NOT EXISTS fiscal_year_read_models (
|
|
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,
|
|
|
|
company_id VARCHAR(255) NOT NULL,
|
|
name VARCHAR(50) NOT NULL,
|
|
start_date DATE NOT NULL,
|
|
end_date DATE NOT NULL,
|
|
status VARCHAR(20) NOT NULL DEFAULT 'open',
|
|
opening_balance_posted BOOLEAN NOT NULL DEFAULT FALSE,
|
|
closing_date TIMESTAMPTZ,
|
|
closed_by VARCHAR(255),
|
|
|
|
CONSTRAINT fk_fiscal_year_company
|
|
FOREIGN KEY (company_id) REFERENCES company_read_models(aggregate_id) ON DELETE CASCADE,
|
|
CONSTRAINT chk_fiscal_year_status
|
|
CHECK (status IN ('open', 'closed', 'locked'))
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_fiscal_year_company ON fiscal_year_read_models(company_id);
|
|
CREATE INDEX IF NOT EXISTS idx_fiscal_year_dates ON fiscal_year_read_models(start_date, end_date);
|
|
|
|
-- Accounting period read models
|
|
CREATE TABLE IF NOT EXISTS accounting_period_read_models (
|
|
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,
|
|
|
|
fiscal_year_id VARCHAR(255) NOT NULL,
|
|
company_id VARCHAR(255) NOT NULL,
|
|
name VARCHAR(50) NOT NULL,
|
|
period_number SMALLINT NOT NULL,
|
|
start_date DATE NOT NULL,
|
|
end_date DATE NOT NULL,
|
|
status VARCHAR(20) NOT NULL DEFAULT 'future',
|
|
closed_at TIMESTAMPTZ,
|
|
closed_by VARCHAR(255),
|
|
reopened_at TIMESTAMPTZ,
|
|
reopened_by VARCHAR(255),
|
|
locked_at TIMESTAMPTZ,
|
|
locked_by VARCHAR(255),
|
|
|
|
CONSTRAINT fk_period_fiscal_year
|
|
FOREIGN KEY (fiscal_year_id) REFERENCES fiscal_year_read_models(aggregate_id) ON DELETE CASCADE,
|
|
CONSTRAINT chk_period_status
|
|
CHECK (status IN ('future', 'open', 'closed', 'locked'))
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_period_fiscal_year ON accounting_period_read_models(fiscal_year_id);
|
|
CREATE INDEX IF NOT EXISTS idx_period_company ON accounting_period_read_models(company_id);
|
|
|
|
-- Account read models (chart of accounts)
|
|
CREATE TABLE IF NOT EXISTS account_read_models (
|
|
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,
|
|
|
|
company_id VARCHAR(255) NOT NULL,
|
|
account_number VARCHAR(10) NOT NULL,
|
|
name VARCHAR(255) NOT NULL,
|
|
account_type VARCHAR(20) NOT NULL,
|
|
parent_id VARCHAR(255),
|
|
description TEXT,
|
|
vat_code_id VARCHAR(255),
|
|
is_active BOOLEAN NOT NULL DEFAULT TRUE,
|
|
is_system_account BOOLEAN NOT NULL DEFAULT FALSE,
|
|
|
|
CONSTRAINT fk_account_company
|
|
FOREIGN KEY (company_id) REFERENCES company_read_models(aggregate_id) ON DELETE CASCADE,
|
|
CONSTRAINT chk_account_type
|
|
CHECK (account_type IN ('asset', 'liability', 'equity', 'revenue', 'cogs', 'expense', 'personnel', 'financial', 'extraordinary'))
|
|
);
|
|
|
|
CREATE UNIQUE INDEX IF NOT EXISTS idx_account_number
|
|
ON account_read_models(company_id, account_number);
|
|
CREATE INDEX IF NOT EXISTS idx_account_company ON account_read_models(company_id);
|
|
CREATE INDEX IF NOT EXISTS idx_account_type ON account_read_models(account_type);
|