nexus/migrations/20260101000010_create_service_sessions.sql
2026-01-26 11:58:04 -05:00

125 lines
4.9 KiB
SQL

-- Migration 010: Create service sessions and related media tables
-- ServiceSession: active work session during a service
-- During session: task completions, notes, photos, videos
-- Service work session
CREATE TABLE service_sessions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
service_id UUID NOT NULL REFERENCES services(id) ON DELETE CASCADE,
account_id UUID NOT NULL REFERENCES accounts(id) ON DELETE CASCADE,
account_address_id UUID NOT NULL REFERENCES account_addresses(id) ON DELETE CASCADE,
customer_id UUID NOT NULL REFERENCES customers(id) ON DELETE CASCADE,
scope_id UUID NOT NULL REFERENCES service_scopes(id) ON DELETE RESTRICT,
date DATE NOT NULL,
start TIMESTAMPTZ NOT NULL,
"end" TIMESTAMPTZ,
created_by_id UUID NOT NULL REFERENCES team_profiles(id) ON DELETE RESTRICT,
closed_by_id UUID REFERENCES team_profiles(id) ON DELETE SET NULL,
-- Constraint: end must be after start (or null for active sessions)
CONSTRAINT service_session_end_gt_start_or_null CHECK ("end" IS NULL OR "end" > start)
);
-- Service task completion record
CREATE TABLE service_task_completions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
service_id UUID NOT NULL REFERENCES services(id) ON DELETE CASCADE,
task_id UUID NOT NULL REFERENCES service_scope_tasks(id) ON DELETE CASCADE,
account_address_id UUID REFERENCES account_addresses(id) ON DELETE SET NULL,
completed_by_id UUID NOT NULL REFERENCES team_profiles(id) ON DELETE RESTRICT,
completed_at TIMESTAMPTZ NOT NULL,
-- For tracking monthly/annual task frequencies
year INTEGER NOT NULL CHECK (year >= 0),
month INTEGER NOT NULL CHECK (month >= 0 AND month <= 12),
notes TEXT
);
-- M2M: Session to task completions
CREATE TABLE service_session_completed_tasks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
session_id UUID NOT NULL REFERENCES service_sessions(id) ON DELETE CASCADE,
task_completion_id UUID NOT NULL REFERENCES service_task_completions(id) ON DELETE CASCADE,
UNIQUE (session_id, task_completion_id)
);
-- Session notes
CREATE TABLE service_session_notes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
session_id UUID NOT NULL REFERENCES service_sessions(id) ON DELETE CASCADE,
content TEXT NOT NULL,
author_id UUID REFERENCES team_profiles(id) ON DELETE SET NULL,
internal BOOLEAN NOT NULL DEFAULT FALSE
);
-- Session images
CREATE TABLE service_session_images (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
session_id UUID NOT NULL REFERENCES service_sessions(id) ON DELETE CASCADE,
title VARCHAR(255) NOT NULL,
image VARCHAR(100) NOT NULL,
thumbnail VARCHAR(100),
content_type VARCHAR(100) NOT NULL,
width INTEGER NOT NULL CHECK (width >= 0),
height INTEGER NOT NULL CHECK (height >= 0),
uploaded_by_team_profile_id UUID REFERENCES team_profiles(id) ON DELETE SET NULL,
notes TEXT NOT NULL DEFAULT '',
internal BOOLEAN NOT NULL DEFAULT FALSE
);
-- Session videos
CREATE TABLE service_session_videos (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
session_id UUID NOT NULL REFERENCES service_sessions(id) ON DELETE CASCADE,
title VARCHAR(255) NOT NULL,
video VARCHAR(100) NOT NULL,
thumbnail VARCHAR(100),
content_type VARCHAR(100) NOT NULL,
width INTEGER NOT NULL CHECK (width >= 0),
height INTEGER NOT NULL CHECK (height >= 0),
duration_seconds INTEGER NOT NULL CHECK (duration_seconds >= 0),
file_size_bytes BIGINT NOT NULL CHECK (file_size_bytes >= 0),
uploaded_by_team_profile_id UUID REFERENCES team_profiles(id) ON DELETE SET NULL,
notes TEXT NOT NULL DEFAULT '',
internal BOOLEAN NOT NULL DEFAULT FALSE
);
-- Indexes
CREATE INDEX idx_service_sessions_service ON service_sessions(service_id);
CREATE INDEX idx_service_sessions_date ON service_sessions(date);
CREATE INDEX idx_service_sessions_created_by ON service_sessions(created_by_id);
CREATE INDEX idx_service_task_completions_service ON service_task_completions(service_id);
CREATE INDEX idx_service_task_completions_task ON service_task_completions(task_id);
CREATE INDEX idx_service_session_notes_session ON service_session_notes(session_id);
CREATE INDEX idx_service_session_images_session ON service_session_images(session_id);
CREATE INDEX idx_service_session_videos_session ON service_session_videos(session_id);