-- Migration: Restructure experiment phases and add machine types -- This migration restructures the experiment system to support separate phase tables -- and machine-specific parameters -- ============================================= -- 1. MACHINE TYPES -- ============================================= -- Create machine types table CREATE TABLE IF NOT EXISTS public.machine_types ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name TEXT NOT NULL UNIQUE, description TEXT, 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) ); -- Machine types will be inserted in seed.sql after user profiles are created -- ============================================= -- 2. UPDATE EXPERIMENT_PHASES TABLE -- ============================================= -- Add phase selection columns to experiment_phases ALTER TABLE public.experiment_phases ADD COLUMN IF NOT EXISTS has_soaking BOOLEAN NOT NULL DEFAULT false, ADD COLUMN IF NOT EXISTS has_airdrying BOOLEAN NOT NULL DEFAULT false, ADD COLUMN IF NOT EXISTS has_cracking BOOLEAN NOT NULL DEFAULT false, ADD COLUMN IF NOT EXISTS has_shelling BOOLEAN NOT NULL DEFAULT false; -- Add constraint to ensure at least one phase is selected ALTER TABLE public.experiment_phases ADD CONSTRAINT check_at_least_one_phase CHECK (has_soaking = true OR has_airdrying = true OR has_cracking = true OR has_shelling = true); -- ============================================= -- 3. CREATE PHASE-SPECIFIC TABLES -- ============================================= -- Create soaking table CREATE TABLE IF NOT EXISTS public.soaking ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE, scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_start_time TIMESTAMP WITH TIME ZONE, soaking_duration_minutes INTEGER NOT NULL CHECK (soaking_duration_minutes > 0), scheduled_end_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_end_time TIMESTAMP WITH TIME ZONE, 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 only one soaking per experiment or repetition CONSTRAINT unique_soaking_per_experiment UNIQUE (experiment_id), CONSTRAINT unique_soaking_per_repetition UNIQUE (repetition_id) ); -- Create airdrying table CREATE TABLE IF NOT EXISTS public.airdrying ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE, scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_start_time TIMESTAMP WITH TIME ZONE, duration_minutes INTEGER NOT NULL CHECK (duration_minutes > 0), scheduled_end_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_end_time TIMESTAMP WITH TIME ZONE, 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 only one airdrying per experiment or repetition CONSTRAINT unique_airdrying_per_experiment UNIQUE (experiment_id), CONSTRAINT unique_airdrying_per_repetition UNIQUE (repetition_id) ); -- Create cracking table CREATE TABLE IF NOT EXISTS public.cracking ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE, machine_type_id UUID NOT NULL REFERENCES public.machine_types(id), scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_start_time TIMESTAMP WITH TIME ZONE, actual_end_time TIMESTAMP WITH TIME ZONE, 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 only one cracking per experiment or repetition CONSTRAINT unique_cracking_per_experiment UNIQUE (experiment_id), CONSTRAINT unique_cracking_per_repetition UNIQUE (repetition_id) ); -- Create shelling table CREATE TABLE IF NOT EXISTS public.shelling ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE, scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_start_time TIMESTAMP WITH TIME ZONE, actual_end_time TIMESTAMP WITH TIME ZONE, 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 only one shelling per experiment or repetition CONSTRAINT unique_shelling_per_experiment UNIQUE (experiment_id), CONSTRAINT unique_shelling_per_repetition UNIQUE (repetition_id) ); -- ============================================= -- 4. MACHINE-SPECIFIC PARAMETER TABLES -- ============================================= -- Create JC Cracker parameters table CREATE TABLE IF NOT EXISTS public.jc_cracker_parameters ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), cracking_id UUID NOT NULL REFERENCES public.cracking(id) ON DELETE CASCADE, plate_contact_frequency_hz DOUBLE PRECISION NOT NULL CHECK (plate_contact_frequency_hz > 0), throughput_rate_pecans_sec DOUBLE PRECISION NOT NULL CHECK (throughput_rate_pecans_sec > 0), crush_amount_in DOUBLE PRECISION NOT NULL CHECK (crush_amount_in >= 0), entry_exit_height_diff_in DOUBLE PRECISION NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Ensure only one parameter set per cracking CONSTRAINT unique_jc_params_per_cracking UNIQUE (cracking_id) ); -- Create Meyer Cracker parameters table CREATE TABLE IF NOT EXISTS public.meyer_cracker_parameters ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), cracking_id UUID NOT NULL REFERENCES public.cracking(id) ON DELETE CASCADE, motor_speed_hz DOUBLE PRECISION NOT NULL CHECK (motor_speed_hz > 0), jig_displacement_inches DOUBLE PRECISION NOT NULL CHECK (jig_displacement_inches >= 0), spring_stiffness_nm DOUBLE PRECISION NOT NULL CHECK (spring_stiffness_nm > 0), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Ensure only one parameter set per cracking CONSTRAINT unique_meyer_params_per_cracking UNIQUE (cracking_id) ); -- ============================================= -- 5. UPDATE EXPERIMENTS TABLE -- ============================================= -- Add weight_per_repetition column ALTER TABLE public.experiments ADD COLUMN IF NOT EXISTS weight_per_repetition_lbs DOUBLE PRECISION NOT NULL DEFAULT 0 CHECK (weight_per_repetition_lbs > 0); -- Remove phase-specific parameters (these will be moved to phase tables) -- Note: We'll keep these columns for now to avoid data loss, but they should be deprecated -- Make old columns nullable to support new schema experiments ALTER TABLE public.experiments ALTER COLUMN soaking_duration_hr DROP NOT NULL, ALTER COLUMN air_drying_time_min DROP NOT NULL, ALTER COLUMN plate_contact_frequency_hz DROP NOT NULL, ALTER COLUMN throughput_rate_pecans_sec DROP NOT NULL, ALTER COLUMN crush_amount_in DROP NOT NULL, ALTER COLUMN entry_exit_height_diff_in DROP NOT NULL; -- ============================================= -- 6. ADD FOREIGN KEY CONSTRAINTS -- ============================================= -- Add foreign key constraints to experiments table for phase associations ALTER TABLE public.experiments ADD COLUMN IF NOT EXISTS soaking_id UUID REFERENCES public.soaking(id) ON DELETE SET NULL, ADD COLUMN IF NOT EXISTS airdrying_id UUID REFERENCES public.airdrying(id) ON DELETE SET NULL, ADD COLUMN IF NOT EXISTS cracking_id UUID REFERENCES public.cracking(id) ON DELETE SET NULL, ADD COLUMN IF NOT EXISTS shelling_id UUID REFERENCES public.shelling(id) ON DELETE SET NULL; -- ============================================= -- 7. CREATE INDEXES FOR PERFORMANCE -- ============================================= -- Create indexes for better query performance CREATE INDEX IF NOT EXISTS idx_soaking_experiment_id ON public.soaking(experiment_id); CREATE INDEX IF NOT EXISTS idx_soaking_repetition_id ON public.soaking(repetition_id); CREATE INDEX IF NOT EXISTS idx_airdrying_experiment_id ON public.airdrying(experiment_id); CREATE INDEX IF NOT EXISTS idx_airdrying_repetition_id ON public.airdrying(repetition_id); CREATE INDEX IF NOT EXISTS idx_cracking_experiment_id ON public.cracking(experiment_id); CREATE INDEX IF NOT EXISTS idx_cracking_repetition_id ON public.cracking(repetition_id); CREATE INDEX IF NOT EXISTS idx_cracking_machine_type_id ON public.cracking(machine_type_id); CREATE INDEX IF NOT EXISTS idx_shelling_experiment_id ON public.shelling(experiment_id); CREATE INDEX IF NOT EXISTS idx_shelling_repetition_id ON public.shelling(repetition_id); -- ============================================= -- 8. CREATE TRIGGERS FOR AUTOMATIC TIMESTAMP CALCULATIONS -- ============================================= -- Function to calculate scheduled end time for soaking CREATE OR REPLACE FUNCTION calculate_soaking_scheduled_end_time() RETURNS TRIGGER AS $$ BEGIN NEW.scheduled_end_time = NEW.scheduled_start_time + (NEW.soaking_duration_minutes || ' minutes')::INTERVAL; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger for soaking scheduled end time DROP TRIGGER IF EXISTS trigger_calculate_soaking_scheduled_end_time ON public.soaking; CREATE TRIGGER trigger_calculate_soaking_scheduled_end_time BEFORE INSERT OR UPDATE ON public.soaking FOR EACH ROW EXECUTE FUNCTION calculate_soaking_scheduled_end_time(); -- Function to calculate scheduled end time for airdrying CREATE OR REPLACE FUNCTION calculate_airdrying_scheduled_end_time() RETURNS TRIGGER AS $$ BEGIN NEW.scheduled_end_time = NEW.scheduled_start_time + (NEW.duration_minutes || ' minutes')::INTERVAL; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger for airdrying scheduled end time DROP TRIGGER IF EXISTS trigger_calculate_airdrying_scheduled_end_time ON public.airdrying; CREATE TRIGGER trigger_calculate_airdrying_scheduled_end_time BEFORE INSERT OR UPDATE ON public.airdrying FOR EACH ROW EXECUTE FUNCTION calculate_airdrying_scheduled_end_time(); -- Function to set airdrying scheduled start time based on soaking end time CREATE OR REPLACE FUNCTION set_airdrying_scheduled_start_time() RETURNS TRIGGER AS $$ BEGIN -- If this is a new airdrying record and no scheduled_start_time is provided, -- try to get it from the associated soaking's scheduled_end_time IF NEW.scheduled_start_time IS NULL THEN SELECT s.scheduled_end_time INTO NEW.scheduled_start_time FROM public.soaking s WHERE s.experiment_id = NEW.experiment_id LIMIT 1; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger for airdrying scheduled start time DROP TRIGGER IF EXISTS trigger_set_airdrying_scheduled_start_time ON public.airdrying; CREATE TRIGGER trigger_set_airdrying_scheduled_start_time BEFORE INSERT ON public.airdrying FOR EACH ROW EXECUTE FUNCTION set_airdrying_scheduled_start_time(); -- Function to set cracking scheduled start time based on airdrying end time CREATE OR REPLACE FUNCTION set_cracking_scheduled_start_time() RETURNS TRIGGER AS $$ BEGIN -- If this is a new cracking record and no scheduled_start_time is provided, -- try to get it from the associated airdrying's scheduled_end_time IF NEW.scheduled_start_time IS NULL THEN SELECT a.scheduled_end_time INTO NEW.scheduled_start_time FROM public.airdrying a WHERE a.experiment_id = NEW.experiment_id LIMIT 1; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger for cracking scheduled start time DROP TRIGGER IF EXISTS trigger_set_cracking_scheduled_start_time ON public.cracking; CREATE TRIGGER trigger_set_cracking_scheduled_start_time BEFORE INSERT ON public.cracking FOR EACH ROW EXECUTE FUNCTION set_cracking_scheduled_start_time(); -- ============================================= -- 9. CREATE VIEWS FOR EASIER QUERYING -- ============================================= -- View for experiments with all phase information CREATE OR REPLACE VIEW public.experiments_with_phases AS SELECT e.id, e.experiment_number, e.reps_required, e.weight_per_repetition_lbs, e.results_status, e.completion_status, e.phase_id, e.soaking_id, e.airdrying_id, e.cracking_id, e.shelling_id, e.created_at, e.updated_at, e.created_by, ep.name as phase_name, ep.description as phase_description, ep.has_soaking, ep.has_airdrying, ep.has_cracking, ep.has_shelling, s.scheduled_start_time as soaking_scheduled_start, s.actual_start_time as soaking_actual_start, s.soaking_duration_minutes, s.scheduled_end_time as soaking_scheduled_end, s.actual_end_time as soaking_actual_end, ad.scheduled_start_time as airdrying_scheduled_start, ad.actual_start_time as airdrying_actual_start, ad.duration_minutes as airdrying_duration, ad.scheduled_end_time as airdrying_scheduled_end, ad.actual_end_time as airdrying_actual_end, c.scheduled_start_time as cracking_scheduled_start, c.actual_start_time as cracking_actual_start, c.actual_end_time as cracking_actual_end, mt.name as machine_type_name, sh.scheduled_start_time as shelling_scheduled_start, sh.actual_start_time as shelling_actual_start, sh.actual_end_time as shelling_actual_end FROM public.experiments e LEFT JOIN public.experiment_phases ep ON e.phase_id = ep.id LEFT JOIN public.soaking s ON e.soaking_id = s.id LEFT JOIN public.airdrying ad ON e.airdrying_id = ad.id LEFT JOIN public.cracking c ON e.cracking_id = c.id LEFT JOIN public.machine_types mt ON c.machine_type_id = mt.id LEFT JOIN public.shelling sh ON e.shelling_id = sh.id; -- View for repetitions with phase information CREATE OR REPLACE VIEW public.repetitions_with_phases AS SELECT er.*, e.experiment_number, e.weight_per_repetition_lbs, ep.name as phase_name, ep.has_soaking, ep.has_airdrying, ep.has_cracking, ep.has_shelling, s.id as soaking_id, s.scheduled_start_time as soaking_scheduled_start, s.actual_start_time as soaking_actual_start, s.soaking_duration_minutes, s.scheduled_end_time as soaking_scheduled_end, s.actual_end_time as soaking_actual_end, ad.id as airdrying_id, ad.scheduled_start_time as airdrying_scheduled_start, ad.actual_start_time as airdrying_actual_start, ad.duration_minutes as airdrying_duration, ad.scheduled_end_time as airdrying_scheduled_end, ad.actual_end_time as airdrying_actual_end, c.id as cracking_id, c.scheduled_start_time as cracking_scheduled_start, c.actual_start_time as cracking_actual_start, c.actual_end_time as cracking_actual_end, mt.name as machine_type_name, sh.id as shelling_id, sh.scheduled_start_time as shelling_scheduled_start, sh.actual_start_time as shelling_actual_start, sh.actual_end_time as shelling_actual_end FROM public.experiment_repetitions er JOIN public.experiments e ON er.experiment_id = e.id LEFT JOIN public.experiment_phases ep ON e.phase_id = ep.id LEFT JOIN public.soaking s ON er.id = s.repetition_id LEFT JOIN public.airdrying ad ON er.id = ad.repetition_id LEFT JOIN public.cracking c ON er.id = c.repetition_id LEFT JOIN public.machine_types mt ON c.machine_type_id = mt.id LEFT JOIN public.shelling sh ON er.id = sh.repetition_id; -- ============================================= -- 10. GRANT PERMISSIONS -- ============================================= -- Grant permissions for new tables GRANT ALL ON public.machine_types TO authenticated; GRANT ALL ON public.soaking TO authenticated; GRANT ALL ON public.airdrying TO authenticated; GRANT ALL ON public.cracking TO authenticated; GRANT ALL ON public.shelling TO authenticated; GRANT ALL ON public.jc_cracker_parameters TO authenticated; GRANT ALL ON public.meyer_cracker_parameters TO authenticated; -- Grant permissions for views GRANT SELECT ON public.experiments_with_phases TO authenticated; GRANT SELECT ON public.repetitions_with_phases TO authenticated; -- ============================================= -- 11. UPDATE RLS POLICIES -- ============================================= -- Enable RLS on new tables ALTER TABLE public.machine_types ENABLE ROW LEVEL SECURITY; ALTER TABLE public.soaking ENABLE ROW LEVEL SECURITY; ALTER TABLE public.airdrying ENABLE ROW LEVEL SECURITY; ALTER TABLE public.cracking ENABLE ROW LEVEL SECURITY; ALTER TABLE public.shelling ENABLE ROW LEVEL SECURITY; ALTER TABLE public.jc_cracker_parameters ENABLE ROW LEVEL SECURITY; ALTER TABLE public.meyer_cracker_parameters ENABLE ROW LEVEL SECURITY; -- Create RLS policies for machine_types (read-only for all authenticated users) CREATE POLICY "Machine types are viewable by authenticated users" ON public.machine_types FOR SELECT USING (auth.role() = 'authenticated'); -- Create RLS policies for phase tables (similar to experiments) CREATE POLICY "Soaking data is viewable by authenticated users" ON public.soaking FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "Soaking data is insertable by authenticated users" ON public.soaking FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "Soaking data is updatable by authenticated users" ON public.soaking FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "Soaking data is deletable by authenticated users" ON public.soaking FOR DELETE USING (auth.role() = 'authenticated'); -- Similar policies for other phase tables CREATE POLICY "Airdrying data is viewable by authenticated users" ON public.airdrying FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "Airdrying data is insertable by authenticated users" ON public.airdrying FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "Airdrying data is updatable by authenticated users" ON public.airdrying FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "Airdrying data is deletable by authenticated users" ON public.airdrying FOR DELETE USING (auth.role() = 'authenticated'); CREATE POLICY "Cracking data is viewable by authenticated users" ON public.cracking FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "Cracking data is insertable by authenticated users" ON public.cracking FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "Cracking data is updatable by authenticated users" ON public.cracking FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "Cracking data is deletable by authenticated users" ON public.cracking FOR DELETE USING (auth.role() = 'authenticated'); CREATE POLICY "Shelling data is viewable by authenticated users" ON public.shelling FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "Shelling data is insertable by authenticated users" ON public.shelling FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "Shelling data is updatable by authenticated users" ON public.shelling FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "Shelling data is deletable by authenticated users" ON public.shelling FOR DELETE USING (auth.role() = 'authenticated'); -- RLS policies for machine parameter tables CREATE POLICY "JC Cracker parameters are viewable by authenticated users" ON public.jc_cracker_parameters FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "JC Cracker parameters are insertable by authenticated users" ON public.jc_cracker_parameters FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "JC Cracker parameters are updatable by authenticated users" ON public.jc_cracker_parameters FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "JC Cracker parameters are deletable by authenticated users" ON public.jc_cracker_parameters FOR DELETE USING (auth.role() = 'authenticated'); CREATE POLICY "Meyer Cracker parameters are viewable by authenticated users" ON public.meyer_cracker_parameters FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "Meyer Cracker parameters are insertable by authenticated users" ON public.meyer_cracker_parameters FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "Meyer Cracker parameters are updatable by authenticated users" ON public.meyer_cracker_parameters FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "Meyer Cracker parameters are deletable by authenticated users" ON public.meyer_cracker_parameters FOR DELETE USING (auth.role() = 'authenticated');