-- Unified Phase Executions Table -- This migration replaces the separate phase tables (soaking, airdrying, cracking, shelling) -- with a unified table that properly supports repetitions -- ============================================= -- 1. CREATE UNIFIED PHASE EXECUTIONS TABLE -- ============================================= CREATE TABLE IF NOT EXISTS public.experiment_phase_executions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), repetition_id UUID NOT NULL REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE, phase_type TEXT NOT NULL CHECK (phase_type IN ('soaking', 'airdrying', 'cracking', 'shelling')), -- Scheduling fields (common to all phases) scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL, scheduled_end_time TIMESTAMP WITH TIME ZONE, actual_start_time TIMESTAMP WITH TIME ZONE, actual_end_time TIMESTAMP WITH TIME ZONE, -- Phase-specific parameters (nullable, only relevant for specific phases) -- Soaking soaking_duration_minutes INTEGER CHECK (soaking_duration_minutes > 0), -- Airdrying duration_minutes INTEGER CHECK (duration_minutes > 0), -- Cracking machine_type_id UUID REFERENCES public.machine_types(id), -- Status tracking status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'scheduled', '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 one execution per phase type per repetition CONSTRAINT unique_phase_per_repetition UNIQUE (repetition_id, phase_type) ); -- ============================================= -- 2. INDEXES FOR PERFORMANCE -- ============================================= CREATE INDEX IF NOT EXISTS idx_phase_executions_repetition_id ON public.experiment_phase_executions(repetition_id); CREATE INDEX IF NOT EXISTS idx_phase_executions_phase_type ON public.experiment_phase_executions(phase_type); CREATE INDEX IF NOT EXISTS idx_phase_executions_status ON public.experiment_phase_executions(status); CREATE INDEX IF NOT EXISTS idx_phase_executions_scheduled_start_time ON public.experiment_phase_executions(scheduled_start_time); CREATE INDEX IF NOT EXISTS idx_phase_executions_machine_type_id ON public.experiment_phase_executions(machine_type_id); CREATE INDEX IF NOT EXISTS idx_phase_executions_created_by ON public.experiment_phase_executions(created_by); -- ============================================= -- 3. FUNCTION: Calculate Sequential Phase Start Times -- ============================================= CREATE OR REPLACE FUNCTION calculate_sequential_phase_start_time() RETURNS TRIGGER AS $$ DECLARE prev_phase_end_time TIMESTAMP WITH TIME ZONE; phase_order TEXT[] := ARRAY['soaking', 'airdrying', 'cracking', 'shelling']; current_phase_index INT; prev_phase_name TEXT; BEGIN -- Find current phase index in the sequence SELECT array_position(phase_order, NEW.phase_type) INTO current_phase_index; -- If not the first phase, get previous phase's end time from the same repetition IF current_phase_index > 1 THEN prev_phase_name := phase_order[current_phase_index - 1]; SELECT scheduled_end_time INTO prev_phase_end_time FROM public.experiment_phase_executions WHERE repetition_id = NEW.repetition_id AND phase_type = prev_phase_name ORDER BY created_at DESC LIMIT 1; -- If previous phase exists and has an end time, use it as start time IF prev_phase_end_time IS NOT NULL THEN NEW.scheduled_start_time := prev_phase_end_time; END IF; END IF; -- Calculate end time based on duration (for phases with duration) IF NEW.phase_type = 'soaking' AND NEW.soaking_duration_minutes IS NOT NULL THEN NEW.scheduled_end_time := NEW.scheduled_start_time + (NEW.soaking_duration_minutes || ' minutes')::INTERVAL; ELSIF NEW.phase_type = 'airdrying' AND NEW.duration_minutes IS NOT NULL THEN NEW.scheduled_end_time := NEW.scheduled_start_time + (NEW.duration_minutes || ' minutes')::INTERVAL; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; -- ============================================= -- 4. FUNCTION: Auto-create Phase Executions for New Repetition -- ============================================= CREATE OR REPLACE FUNCTION create_phase_executions_for_repetition() RETURNS TRIGGER AS $$ DECLARE exp_phase_config RECORD; phase_type_list TEXT[] := ARRAY[]::TEXT[]; phase_name TEXT; BEGIN -- Get experiment phase configuration -- Note: Phase durations may need to be set later when scheduling SELECT ep.has_soaking, ep.has_airdrying, ep.has_cracking, ep.has_shelling, ep.cracking_machine_type_id INTO exp_phase_config FROM public.experiments e JOIN public.experiment_phases ep ON e.phase_id = ep.id WHERE e.id = NEW.experiment_id; -- Build list of phases to create based on experiment configuration IF exp_phase_config.has_soaking THEN phase_type_list := array_append(phase_type_list, 'soaking'); END IF; IF exp_phase_config.has_airdrying THEN phase_type_list := array_append(phase_type_list, 'airdrying'); END IF; IF exp_phase_config.has_cracking THEN phase_type_list := array_append(phase_type_list, 'cracking'); END IF; IF exp_phase_config.has_shelling THEN phase_type_list := array_append(phase_type_list, 'shelling'); END IF; -- Create phase executions for each required phase FOREACH phase_name IN ARRAY phase_type_list LOOP INSERT INTO public.experiment_phase_executions ( repetition_id, phase_type, scheduled_start_time, status, created_by, -- Phase-specific parameters soaking_duration_minutes, duration_minutes, machine_type_id ) VALUES ( NEW.id, phase_name, NOW(), -- Default start time, will be updated when scheduled or by sequential calculation 'pending', NEW.created_by, -- Set phase-specific parameters -- Note: Durations will be set when the repetition is scheduled -- These can be NULL initially and updated later NULL, -- soaking_duration_minutes (set when scheduled) NULL, -- duration_minutes (set when scheduled) CASE WHEN phase_name = 'cracking' THEN exp_phase_config.cracking_machine_type_id ELSE NULL END ); END LOOP; RETURN NEW; END; $$ LANGUAGE plpgsql; -- ============================================= -- 5. TRIGGERS -- ============================================= -- Trigger to automatically calculate sequential times and durations CREATE TRIGGER trigger_calculate_sequential_phase_times BEFORE INSERT OR UPDATE ON public.experiment_phase_executions FOR EACH ROW EXECUTE FUNCTION calculate_sequential_phase_start_time(); -- Trigger to auto-create phases when repetition is created CREATE TRIGGER trigger_create_phase_executions AFTER INSERT ON public.experiment_repetitions FOR EACH ROW EXECUTE FUNCTION create_phase_executions_for_repetition(); -- Trigger for updated_at CREATE TRIGGER set_updated_at_phase_executions BEFORE UPDATE ON public.experiment_phase_executions FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); -- ============================================= -- 6. CREATE VIEWS FOR PHASE-SPECIFIC ACCESS (Backward Compatibility) -- ============================================= -- These views allow existing code to work with phase-specific "tables" CREATE OR REPLACE VIEW public.soaking_view AS SELECT id, (SELECT experiment_id FROM experiment_repetitions WHERE id = repetition_id) as experiment_id, repetition_id, scheduled_start_time, actual_start_time, soaking_duration_minutes, scheduled_end_time, actual_end_time, created_at, updated_at, created_by FROM public.experiment_phase_executions WHERE phase_type = 'soaking'; CREATE OR REPLACE VIEW public.airdrying_view AS SELECT id, (SELECT experiment_id FROM experiment_repetitions WHERE id = repetition_id) as experiment_id, repetition_id, scheduled_start_time, actual_start_time, duration_minutes, scheduled_end_time, actual_end_time, created_at, updated_at, created_by FROM public.experiment_phase_executions WHERE phase_type = 'airdrying'; CREATE OR REPLACE VIEW public.cracking_view AS SELECT id, (SELECT experiment_id FROM experiment_repetitions WHERE id = repetition_id) as experiment_id, repetition_id, machine_type_id, scheduled_start_time, actual_start_time, actual_end_time, created_at, updated_at, created_by FROM public.experiment_phase_executions WHERE phase_type = 'cracking'; CREATE OR REPLACE VIEW public.shelling_view AS SELECT id, (SELECT experiment_id FROM experiment_repetitions WHERE id = repetition_id) as experiment_id, repetition_id, scheduled_start_time, actual_start_time, actual_end_time, created_at, updated_at, created_by FROM public.experiment_phase_executions WHERE phase_type = 'shelling'; -- ============================================= -- 7. GRANT PERMISSIONS -- ============================================= GRANT ALL ON public.experiment_phase_executions TO authenticated; GRANT SELECT ON public.soaking_view TO authenticated; GRANT SELECT ON public.airdrying_view TO authenticated; GRANT SELECT ON public.cracking_view TO authenticated; GRANT SELECT ON public.shelling_view TO authenticated; -- ============================================= -- 8. ENABLE ROW LEVEL SECURITY -- ============================================= ALTER TABLE public.experiment_phase_executions ENABLE ROW LEVEL SECURITY; -- ============================================= -- 9. CREATE RLS POLICIES -- ============================================= CREATE POLICY "Phase executions are viewable by authenticated users" ON public.experiment_phase_executions FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "Phase executions are insertable by authenticated users" ON public.experiment_phase_executions FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "Phase executions are updatable by authenticated users" ON public.experiment_phase_executions FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "Phase executions are deletable by authenticated users" ON public.experiment_phase_executions FOR DELETE USING (auth.role() = 'authenticated');