-- Data Entry Tables -- This migration creates the phase-specific data entry tables (soaking, airdrying, cracking, shelling) -- ============================================= -- 1. SOAKING TABLE -- ============================================= -- 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_hours DOUBLE PRECISION NOT NULL CHECK (soaking_duration_hours > 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) ); -- ============================================= -- 2. AIRDRYING TABLE -- ============================================= -- 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) ); -- ============================================= -- 3. CRACKING TABLE -- ============================================= -- 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), jc_cracker_parameters_id UUID REFERENCES public.jc_cracker_parameters(id) ON DELETE SET NULL, meyer_cracker_parameters_id UUID REFERENCES public.meyer_cracker_parameters(id) ON DELETE SET NULL, 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), -- Ensure exactly one cracker parameter set is specified CONSTRAINT check_exactly_one_cracker_params CHECK ( (jc_cracker_parameters_id IS NOT NULL AND meyer_cracker_parameters_id IS NULL) OR (jc_cracker_parameters_id IS NULL AND meyer_cracker_parameters_id IS NOT NULL) ) ); -- ============================================= -- 4. SHELLING TABLE -- ============================================= -- 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) ); -- ============================================= -- 5. 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(), 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() ); -- Create Meyer Cracker parameters table CREATE TABLE IF NOT EXISTS public.meyer_cracker_parameters ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), motor_speed_hz DOUBLE PRECISION NOT NULL CHECK (motor_speed_hz > 0), jig_displacement_inches DOUBLE PRECISION NOT NULL, 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() ); -- ============================================= -- 6. EXPERIMENTS TABLE DOES NOT NEED FOREIGN KEYS TO PHASE TABLES -- ============================================= -- Phase tables reference experiments via experiment_id -- Experiments inherit phase configuration from experiment_phases via phase_id -- ============================================= -- 7. INDEXES FOR PERFORMANCE -- ============================================= -- Create indexes for experiment_id references CREATE INDEX IF NOT EXISTS idx_soaking_experiment_id ON public.soaking(experiment_id); CREATE INDEX IF NOT EXISTS idx_airdrying_experiment_id ON public.airdrying(experiment_id); CREATE INDEX IF NOT EXISTS idx_cracking_experiment_id ON public.cracking(experiment_id); CREATE INDEX IF NOT EXISTS idx_shelling_experiment_id ON public.shelling(experiment_id); -- Create indexes for repetition references CREATE INDEX IF NOT EXISTS idx_soaking_repetition_id ON public.soaking(repetition_id); CREATE INDEX IF NOT EXISTS idx_airdrying_repetition_id ON public.airdrying(repetition_id); CREATE INDEX IF NOT EXISTS idx_cracking_repetition_id ON public.cracking(repetition_id); CREATE INDEX IF NOT EXISTS idx_shelling_repetition_id ON public.shelling(repetition_id); -- Create indexes for machine type references CREATE INDEX IF NOT EXISTS idx_cracking_machine_type_id ON public.cracking(machine_type_id); -- Create indexes for created_by references CREATE INDEX IF NOT EXISTS idx_soaking_created_by ON public.soaking(created_by); CREATE INDEX IF NOT EXISTS idx_airdrying_created_by ON public.airdrying(created_by); CREATE INDEX IF NOT EXISTS idx_cracking_created_by ON public.cracking(created_by); CREATE INDEX IF NOT EXISTS idx_shelling_created_by ON public.shelling(created_by); -- ============================================= -- 8. 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_hours || ' hours')::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. TRIGGERS FOR UPDATED_AT -- ============================================= -- Create triggers for updated_at on all phase tables CREATE TRIGGER set_updated_at_soaking BEFORE UPDATE ON public.soaking FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_airdrying BEFORE UPDATE ON public.airdrying FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_cracking BEFORE UPDATE ON public.cracking FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_shelling BEFORE UPDATE ON public.shelling FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_jc_cracker_parameters BEFORE UPDATE ON public.jc_cracker_parameters FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_meyer_cracker_parameters BEFORE UPDATE ON public.meyer_cracker_parameters FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); -- ============================================= -- 10. GRANT PERMISSIONS -- ============================================= 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; -- ============================================= -- 11. 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; -- ============================================= -- 12. CREATE RLS POLICIES -- ============================================= -- Create RLS policies for phase tables 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'); 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');