-- Migration 007: Create project scope tables -- ProjectScope: assigned directly to a Project (not location-based) -- Structure: ProjectScope → ProjectScopeCategory → ProjectScopeTask -- Forward declaration: projects table will be created in migration 009 -- We create project_scopes with a deferred FK constraint -- Project scope assigned directly to a project CREATE TABLE project_scopes ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), name VARCHAR(255) NOT NULL, description TEXT, -- Project reference (FK added in migration 009 after projects table exists) project_id UUID NOT NULL, -- Optional: if project is at a specific location account_id UUID REFERENCES accounts(id) ON DELETE SET NULL, account_address_id UUID REFERENCES account_addresses(id) ON DELETE SET NULL, is_active BOOLEAN NOT NULL DEFAULT TRUE ); -- Category within a project scope (equivalent to Area for services) CREATE TABLE project_scope_categories ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), scope_id UUID NOT NULL REFERENCES project_scopes(id) ON DELETE CASCADE, name VARCHAR(255) NOT NULL, "order" INTEGER NOT NULL CHECK ("order" >= 0) ); -- Task within a project scope category CREATE TABLE project_scope_tasks ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), category_id UUID NOT NULL REFERENCES project_scope_categories(id) ON DELETE CASCADE, -- Three descriptions for different audiences scope_description TEXT NOT NULL, -- Customer-facing checklist_description TEXT NOT NULL, -- QA/punchlist format session_description TEXT NOT NULL, -- Team member work instructions frequency task_frequency NOT NULL DEFAULT 'AS_NEEDED', "order" INTEGER NOT NULL CHECK ("order" >= 0), estimated_minutes INTEGER CHECK (estimated_minutes >= 0) ); -- Indexes CREATE INDEX idx_project_scopes_project ON project_scopes(project_id); CREATE INDEX idx_project_scopes_account ON project_scopes(account_id); CREATE INDEX idx_project_scope_categories_scope ON project_scope_categories(scope_id); CREATE INDEX idx_project_scope_tasks_category ON project_scope_tasks(category_id);