69 lines
2.2 KiB
SQL
69 lines
2.2 KiB
SQL
-- Migration 004: Create account hierarchy tables
|
|
-- Account: business entity under a Customer
|
|
-- AccountAddress: location (where work happens)
|
|
-- AccountContact: contact person at account (exactly ONE active per account)
|
|
|
|
-- Business entity under a customer
|
|
CREATE TABLE accounts (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
|
|
customer_id UUID NOT NULL REFERENCES customers(id) ON DELETE CASCADE,
|
|
|
|
name VARCHAR(200) NOT NULL,
|
|
status entity_status NOT NULL DEFAULT 'ACTIVE',
|
|
|
|
start_date DATE NOT NULL,
|
|
end_date DATE
|
|
);
|
|
|
|
-- Physical locations for accounts (where work happens)
|
|
CREATE TABLE account_addresses (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
|
|
account_id UUID NOT NULL REFERENCES accounts(id) ON DELETE CASCADE,
|
|
|
|
name VARCHAR(200) NOT NULL,
|
|
street_address VARCHAR(255) NOT NULL,
|
|
city VARCHAR(100) NOT NULL,
|
|
state VARCHAR(100) NOT NULL,
|
|
zip_code VARCHAR(20) NOT NULL,
|
|
|
|
is_active BOOLEAN NOT NULL DEFAULT TRUE,
|
|
is_primary BOOLEAN NOT NULL DEFAULT FALSE,
|
|
|
|
notes TEXT
|
|
);
|
|
|
|
-- Contact persons at accounts
|
|
CREATE TABLE account_contacts (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
|
|
account_id UUID NOT NULL REFERENCES accounts(id) ON DELETE CASCADE,
|
|
|
|
first_name VARCHAR(100) NOT NULL,
|
|
last_name VARCHAR(100) NOT NULL,
|
|
phone VARCHAR(20),
|
|
email VARCHAR(254) NOT NULL,
|
|
|
|
is_active BOOLEAN NOT NULL DEFAULT TRUE,
|
|
is_primary BOOLEAN NOT NULL DEFAULT FALSE,
|
|
|
|
notes TEXT
|
|
);
|
|
|
|
-- Constraint: exactly ONE active contact per account
|
|
CREATE UNIQUE INDEX idx_account_contact_active
|
|
ON account_contacts (account_id) WHERE is_active = TRUE;
|
|
|
|
-- Indexes
|
|
CREATE INDEX idx_accounts_customer ON accounts(customer_id);
|
|
CREATE INDEX idx_accounts_status ON accounts(status);
|
|
CREATE INDEX idx_account_addresses_account ON account_addresses(account_id);
|
|
CREATE INDEX idx_account_contacts_account ON account_contacts(account_id);
|