nexus/migrations/20260101000009_create_projects.sql
2026-01-26 11:58:04 -05:00

72 lines
2.7 KiB
SQL

-- Migration 009: Create projects table and add FK to project_scopes
-- Project: one-time work, MUST have Customer, MAY have AccountAddress
-- Project (one-time work)
CREATE TABLE projects (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
-- MUST have a customer
customer_id UUID NOT NULL REFERENCES customers(id) ON DELETE CASCADE,
-- MAY have a location (AccountAddress) OR standalone address
account_address_id UUID REFERENCES account_addresses(id) ON DELETE SET NULL,
-- Standalone address (used when account_address_id is NULL)
street_address VARCHAR(255),
city VARCHAR(100),
state VARCHAR(100),
zip_code VARCHAR(20),
-- XOR constraint: either account_address OR standalone address
CONSTRAINT project_addr_xor_check CHECK (
(account_address_id IS NOT NULL AND street_address IS NULL AND city IS NULL AND state IS NULL AND zip_code IS NULL)
OR
(account_address_id IS NULL AND street_address IS NOT NULL AND city IS NOT NULL AND state IS NOT NULL AND zip_code IS NOT NULL)
OR
(account_address_id IS NULL AND street_address IS NULL AND city IS NULL AND state IS NULL AND zip_code IS NULL)
),
name VARCHAR(200) NOT NULL,
date DATE NOT NULL,
status work_status NOT NULL DEFAULT 'SCHEDULED',
notes TEXT,
-- Financials
labor DECIMAL(10, 2) NOT NULL DEFAULT 0,
amount DECIMAL(10, 2) NOT NULL DEFAULT 0,
-- Scope reference (optional, assigned directly to project)
scope_id UUID REFERENCES project_scopes(id) ON DELETE SET NULL,
-- External integrations
calendar_event_id VARCHAR(255),
wave_service_id VARCHAR(255)
);
-- Now add FK from project_scopes to projects
ALTER TABLE project_scopes
ADD CONSTRAINT fk_project_scopes_project
FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE;
-- M2M: Project to TeamProfile (assigned team members)
CREATE TABLE project_team_members (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
team_profile_id UUID NOT NULL REFERENCES team_profiles(id) ON DELETE CASCADE,
UNIQUE (project_id, team_profile_id)
);
-- Indexes
CREATE INDEX idx_projects_customer ON projects(customer_id);
CREATE INDEX idx_projects_address ON projects(account_address_id);
CREATE INDEX idx_projects_date ON projects(date);
CREATE INDEX idx_projects_status ON projects(status);
CREATE INDEX idx_project_team_members_project ON project_team_members(project_id);
CREATE INDEX idx_project_team_members_team ON project_team_members(team_profile_id);