- Deleted unused CSV files: 'meyer experiments.csv' and 'phase_2_experimental_run_sheet.csv'. - Updated SQL seed scripts to reflect changes in experiment data structure and ensure consistency with the latest experiment parameters. - Enhanced user role assignments in the seed data to include 'conductor' alongside 'data recorder'. - Adjusted experiment seeding logic to align with the corrected data from the CSV files.
134 lines
5.0 KiB
PL/PgSQL
134 lines
5.0 KiB
PL/PgSQL
-- Fix soaking duration column to use minutes instead of hours
|
|
-- This aligns the database schema with frontend expectations and seed data
|
|
|
|
BEGIN;
|
|
|
|
-- 1) Add new soaking_duration_minutes column
|
|
ALTER TABLE public.soaking ADD COLUMN IF NOT EXISTS soaking_duration_minutes INTEGER;
|
|
|
|
-- 2) Backfill soaking_duration_minutes from soaking_duration_hours
|
|
UPDATE public.soaking
|
|
SET soaking_duration_minutes = ROUND(soaking_duration_hours * 60)
|
|
WHERE soaking_duration_minutes IS NULL;
|
|
|
|
-- 3) Make soaking_duration_minutes NOT NULL
|
|
ALTER TABLE public.soaking ALTER COLUMN soaking_duration_minutes SET NOT NULL;
|
|
|
|
-- 4) Add check constraint for positive values
|
|
ALTER TABLE public.soaking ADD CONSTRAINT check_soaking_duration_minutes_positive
|
|
CHECK (soaking_duration_minutes > 0);
|
|
|
|
-- 5) Drop and recreate views to use the new column (must be done before dropping old column)
|
|
DROP VIEW IF EXISTS public.experiments_with_phases;
|
|
DROP VIEW IF EXISTS public.repetitions_with_phases;
|
|
|
|
CREATE 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;
|
|
|
|
CREATE VIEW public.repetitions_with_phases AS
|
|
SELECT
|
|
er.id,
|
|
er.experiment_number,
|
|
er.experiment_phase_id,
|
|
er.repetition_number,
|
|
er.status,
|
|
er.created_at,
|
|
er.updated_at,
|
|
er.created_by,
|
|
e.weight_per_repetition_lbs,
|
|
ep.name as phase_name,
|
|
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.experiment_repetitions er
|
|
JOIN public.experiments e ON er.experiment_number = e.experiment_number AND er.experiment_phase_id = e.phase_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;
|
|
|
|
-- 6) Update the trigger function to use minutes
|
|
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;
|
|
|
|
-- 7) Update the trigger to use the new column
|
|
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();
|
|
|
|
-- 8) Drop the old soaking_duration_hours column
|
|
ALTER TABLE public.soaking DROP COLUMN IF EXISTS soaking_duration_hours;
|
|
|
|
COMMIT;
|