-- Migration 006: Create service scope tables -- ServiceScope: assigned at AccountAddress level (exactly ONE active per location) -- Structure: ServiceScope → ServiceScopeArea → ServiceScopeTask -- Service scope assigned to an account address (location) CREATE TABLE service_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, account_id UUID NOT NULL REFERENCES accounts(id) ON DELETE CASCADE, account_address_id UUID NOT NULL REFERENCES account_addresses(id) ON DELETE CASCADE, is_active BOOLEAN NOT NULL DEFAULT TRUE ); -- Constraint: exactly ONE active service scope per account address CREATE UNIQUE INDEX idx_service_scope_active ON service_scopes (account_address_id) WHERE is_active = TRUE; -- Area within a service scope CREATE TABLE service_scope_areas ( 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 service_scopes(id) ON DELETE CASCADE, name VARCHAR(100) NOT NULL, "order" INTEGER NOT NULL CHECK ("order" >= 0) ); -- Task within a service scope area CREATE TABLE service_scope_tasks ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), area_id UUID NOT NULL REFERENCES service_scope_areas(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 'DAILY', "order" INTEGER NOT NULL CHECK ("order" >= 0), estimated_minutes INTEGER CHECK (estimated_minutes >= 0) ); -- Indexes CREATE INDEX idx_service_scopes_account ON service_scopes(account_id); CREATE INDEX idx_service_scopes_address ON service_scopes(account_address_id); CREATE INDEX idx_service_scope_areas_scope ON service_scope_areas(scope_id); CREATE INDEX idx_service_scope_tasks_area ON service_scope_tasks(area_id);