-- Experiments and Repetitions -- This migration creates the experiments and experiment repetitions tables with composite primary key -- ============================================= -- 1. EXPERIMENTS -- ============================================= -- Create experiments table with composite primary key (experiment_number, phase_id) CREATE TABLE IF NOT EXISTS public.experiments ( id UUID DEFAULT uuid_generate_v4(), experiment_number INTEGER NOT NULL, reps_required INTEGER NOT NULL CHECK (reps_required > 0), weight_per_repetition_lbs DOUBLE PRECISION NOT NULL DEFAULT 5.0 CHECK (weight_per_repetition_lbs > 0), results_status TEXT NOT NULL DEFAULT 'valid' CHECK (results_status IN ('valid', 'invalid')), completion_status BOOLEAN NOT NULL DEFAULT false, phase_id UUID NOT NULL REFERENCES public.experiment_phases(id) ON DELETE SET NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by UUID NOT NULL REFERENCES public.user_profiles(id), -- Composite primary key allows each phase to have its own experiment numbering starting from 1 PRIMARY KEY (experiment_number, phase_id) ); -- ============================================= -- 2. EXPERIMENT REPETITIONS -- ============================================= -- Create experiment repetitions table CREATE TABLE IF NOT EXISTS public.experiment_repetitions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_number INTEGER NOT NULL CHECK (repetition_number > 0), status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'in_progress', 'completed', 'cancelled')), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by UUID NOT NULL REFERENCES public.user_profiles(id), -- Ensure unique repetition numbers per experiment UNIQUE(experiment_id, repetition_number) ); -- ============================================= -- 3. INDEXES FOR PERFORMANCE -- ============================================= CREATE INDEX IF NOT EXISTS idx_experiments_phase_id ON public.experiments(phase_id); CREATE INDEX IF NOT EXISTS idx_experiments_experiment_number ON public.experiments(experiment_number); CREATE INDEX IF NOT EXISTS idx_experiments_created_by ON public.experiments(created_by); CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_id ON public.experiment_repetitions(experiment_id); CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_created_by ON public.experiment_repetitions(created_by); -- ============================================= -- 4. TRIGGERS -- ============================================= -- Create trigger for updated_at on experiments CREATE TRIGGER set_updated_at_experiments BEFORE UPDATE ON public.experiments FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); -- Create trigger for updated_at on experiment_repetitions CREATE TRIGGER set_updated_at_experiment_repetitions BEFORE UPDATE ON public.experiment_repetitions FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); -- ============================================= -- 5. GRANT PERMISSIONS -- ============================================= GRANT ALL ON public.experiments TO authenticated; GRANT ALL ON public.experiment_repetitions TO authenticated; -- ============================================= -- 6. ENABLE ROW LEVEL SECURITY -- ============================================= ALTER TABLE public.experiments ENABLE ROW LEVEL SECURITY; ALTER TABLE public.experiment_repetitions ENABLE ROW LEVEL SECURITY; -- ============================================= -- 7. CREATE RLS POLICIES -- ============================================= -- Create RLS policies for experiments CREATE POLICY "Experiments are viewable by authenticated users" ON public.experiments FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "Experiments are insertable by authenticated users" ON public.experiments FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "Experiments are updatable by authenticated users" ON public.experiments FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "Experiments are deletable by authenticated users" ON public.experiments FOR DELETE USING (auth.role() = 'authenticated'); -- Create RLS policies for experiment_repetitions CREATE POLICY "Experiment repetitions are viewable by authenticated users" ON public.experiment_repetitions FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "Experiment repetitions are insertable by authenticated users" ON public.experiment_repetitions FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "Experiment repetitions are updatable by authenticated users" ON public.experiment_repetitions FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "Experiment repetitions are deletable by authenticated users" ON public.experiment_repetitions FOR DELETE USING (auth.role() = 'authenticated');