- Renamed columns in the experimental run sheet CSV for clarity. - Updated the ExperimentForm component to include new fields for weight per repetition and additional parameters specific to Meyer Cracker experiments. - Enhanced the data entry logic to handle new experiment phases and machine types. - Refactored repetition scheduling logic to use scheduled_date instead of schedule_status for better clarity in status representation. - Improved the user interface for displaying experiment phases and their associated statuses. - Removed outdated seed data and updated database migration scripts to reflect the new schema changes.
186 lines
8.0 KiB
SQL
186 lines
8.0 KiB
SQL
-- Migration: Change experiments table to use composite primary key (experiment_number, phase_id)
|
|
-- This allows each phase to have its own experiment numbering starting from 1
|
|
|
|
-- =============================================
|
|
-- 1. DROP EXISTING FOREIGN KEY CONSTRAINTS
|
|
-- =============================================
|
|
|
|
-- Drop foreign key constraints that reference experiments table
|
|
ALTER TABLE public.experiment_repetitions DROP CONSTRAINT IF EXISTS experiment_repetitions_experiment_id_fkey;
|
|
ALTER TABLE public.soaking DROP CONSTRAINT IF EXISTS soaking_experiment_id_fkey;
|
|
ALTER TABLE public.airdrying DROP CONSTRAINT IF EXISTS airdrying_experiment_id_fkey;
|
|
ALTER TABLE public.cracking DROP CONSTRAINT IF EXISTS cracking_experiment_id_fkey;
|
|
ALTER TABLE public.shelling DROP CONSTRAINT IF EXISTS shelling_experiment_id_fkey;
|
|
ALTER TABLE public.conductor_availability DROP CONSTRAINT IF EXISTS conductor_availability_experiment_id_fkey;
|
|
|
|
-- =============================================
|
|
-- 2. MODIFY EXPERIMENTS TABLE
|
|
-- =============================================
|
|
|
|
-- Drop the existing primary key and unique constraint
|
|
ALTER TABLE public.experiments DROP CONSTRAINT IF EXISTS experiments_pkey;
|
|
ALTER TABLE public.experiments DROP CONSTRAINT IF EXISTS experiments_experiment_number_key;
|
|
|
|
-- Make phase_id NOT NULL since it's now part of the primary key
|
|
ALTER TABLE public.experiments ALTER COLUMN phase_id SET NOT NULL;
|
|
|
|
-- Add composite primary key
|
|
ALTER TABLE public.experiments ADD CONSTRAINT experiments_pkey PRIMARY KEY (experiment_number, phase_id);
|
|
|
|
-- =============================================
|
|
-- 3. UPDATE FOREIGN KEY COLUMNS
|
|
-- =============================================
|
|
|
|
-- Add phase_id columns to tables that reference experiments
|
|
ALTER TABLE public.experiment_repetitions ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
|
ALTER TABLE public.soaking ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
|
ALTER TABLE public.airdrying ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
|
ALTER TABLE public.cracking ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
|
ALTER TABLE public.shelling ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
|
ALTER TABLE public.conductor_availability ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
|
|
|
-- Populate the phase_id columns from the experiments table
|
|
UPDATE public.experiment_repetitions
|
|
SET experiment_phase_id = e.phase_id
|
|
FROM public.experiments e
|
|
WHERE experiment_repetitions.experiment_id = e.id;
|
|
|
|
UPDATE public.soaking
|
|
SET experiment_phase_id = e.phase_id
|
|
FROM public.experiments e
|
|
WHERE soaking.experiment_id = e.id;
|
|
|
|
UPDATE public.airdrying
|
|
SET experiment_phase_id = e.phase_id
|
|
FROM public.experiments e
|
|
WHERE airdrying.experiment_id = e.id;
|
|
|
|
UPDATE public.cracking
|
|
SET experiment_phase_id = e.phase_id
|
|
FROM public.experiments e
|
|
WHERE cracking.experiment_id = e.id;
|
|
|
|
UPDATE public.shelling
|
|
SET experiment_phase_id = e.phase_id
|
|
FROM public.experiments e
|
|
WHERE shelling.experiment_id = e.id;
|
|
|
|
UPDATE public.conductor_availability
|
|
SET experiment_phase_id = e.phase_id
|
|
FROM public.experiments e
|
|
WHERE conductor_availability.experiment_id = e.id;
|
|
|
|
-- Make the phase_id columns NOT NULL
|
|
ALTER TABLE public.experiment_repetitions ALTER COLUMN experiment_phase_id SET NOT NULL;
|
|
ALTER TABLE public.soaking ALTER COLUMN experiment_phase_id SET NOT NULL;
|
|
ALTER TABLE public.airdrying ALTER COLUMN experiment_phase_id SET NOT NULL;
|
|
ALTER TABLE public.cracking ALTER COLUMN experiment_phase_id SET NOT NULL;
|
|
ALTER TABLE public.shelling ALTER COLUMN experiment_phase_id SET NOT NULL;
|
|
ALTER TABLE public.conductor_availability ALTER COLUMN experiment_phase_id SET NOT NULL;
|
|
|
|
-- =============================================
|
|
-- 4. ADD NEW FOREIGN KEY CONSTRAINTS
|
|
-- =============================================
|
|
|
|
-- Add foreign key constraints using composite key
|
|
ALTER TABLE public.experiment_repetitions
|
|
ADD CONSTRAINT experiment_repetitions_experiment_fkey
|
|
FOREIGN KEY (experiment_id, experiment_phase_id)
|
|
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
|
|
|
ALTER TABLE public.soaking
|
|
ADD CONSTRAINT soaking_experiment_fkey
|
|
FOREIGN KEY (experiment_id, experiment_phase_id)
|
|
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
|
|
|
ALTER TABLE public.airdrying
|
|
ADD CONSTRAINT airdrying_experiment_fkey
|
|
FOREIGN KEY (experiment_id, experiment_phase_id)
|
|
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
|
|
|
ALTER TABLE public.cracking
|
|
ADD CONSTRAINT cracking_experiment_fkey
|
|
FOREIGN KEY (experiment_id, experiment_phase_id)
|
|
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
|
|
|
ALTER TABLE public.shelling
|
|
ADD CONSTRAINT shelling_experiment_fkey
|
|
FOREIGN KEY (experiment_id, experiment_phase_id)
|
|
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
|
|
|
ALTER TABLE public.conductor_availability
|
|
ADD CONSTRAINT conductor_availability_experiment_fkey
|
|
FOREIGN KEY (experiment_id, experiment_phase_id)
|
|
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
|
|
|
-- =============================================
|
|
-- 5. UPDATE UNIQUE CONSTRAINTS
|
|
-- =============================================
|
|
|
|
-- Update unique constraints to use composite key
|
|
ALTER TABLE public.experiment_repetitions
|
|
DROP CONSTRAINT IF EXISTS experiment_repetitions_experiment_id_repetition_number_key;
|
|
|
|
ALTER TABLE public.experiment_repetitions
|
|
ADD CONSTRAINT experiment_repetitions_experiment_repetition_key
|
|
UNIQUE (experiment_id, experiment_phase_id, repetition_number);
|
|
|
|
-- Update unique constraints for phase tables
|
|
ALTER TABLE public.soaking
|
|
DROP CONSTRAINT IF EXISTS unique_soaking_per_experiment;
|
|
|
|
ALTER TABLE public.soaking
|
|
ADD CONSTRAINT unique_soaking_per_experiment
|
|
UNIQUE (experiment_id, experiment_phase_id);
|
|
|
|
ALTER TABLE public.airdrying
|
|
DROP CONSTRAINT IF EXISTS unique_airdrying_per_experiment;
|
|
|
|
ALTER TABLE public.airdrying
|
|
ADD CONSTRAINT unique_airdrying_per_experiment
|
|
UNIQUE (experiment_id, experiment_phase_id);
|
|
|
|
ALTER TABLE public.cracking
|
|
DROP CONSTRAINT IF EXISTS unique_cracking_per_experiment;
|
|
|
|
ALTER TABLE public.cracking
|
|
ADD CONSTRAINT unique_cracking_per_experiment
|
|
UNIQUE (experiment_id, experiment_phase_id);
|
|
|
|
ALTER TABLE public.shelling
|
|
DROP CONSTRAINT IF EXISTS unique_shelling_per_experiment;
|
|
|
|
ALTER TABLE public.shelling
|
|
ADD CONSTRAINT unique_shelling_per_experiment
|
|
UNIQUE (experiment_id, experiment_phase_id);
|
|
|
|
-- =============================================
|
|
-- 6. UPDATE INDEXES
|
|
-- =============================================
|
|
|
|
-- Drop old indexes
|
|
DROP INDEX IF EXISTS idx_soaking_experiment_id;
|
|
DROP INDEX IF EXISTS idx_airdrying_experiment_id;
|
|
DROP INDEX IF EXISTS idx_cracking_experiment_id;
|
|
DROP INDEX IF EXISTS idx_shelling_experiment_id;
|
|
|
|
-- Create new composite indexes
|
|
CREATE INDEX IF NOT EXISTS idx_soaking_experiment_composite ON public.soaking(experiment_id, experiment_phase_id);
|
|
CREATE INDEX IF NOT EXISTS idx_airdrying_experiment_composite ON public.airdrying(experiment_id, experiment_phase_id);
|
|
CREATE INDEX IF NOT EXISTS idx_cracking_experiment_composite ON public.cracking(experiment_id, experiment_phase_id);
|
|
CREATE INDEX IF NOT EXISTS idx_shelling_experiment_composite ON public.shelling(experiment_id, experiment_phase_id);
|
|
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_composite ON public.experiment_repetitions(experiment_id, experiment_phase_id);
|
|
CREATE INDEX IF NOT EXISTS idx_conductor_availability_experiment_composite ON public.conductor_availability(experiment_id, experiment_phase_id);
|
|
|
|
-- =============================================
|
|
-- 7. UPDATE EXPERIMENTS TABLE FOREIGN KEY REFERENCES
|
|
-- =============================================
|
|
|
|
-- The experiments table has foreign key references to phase tables
|
|
-- These need to be updated to use the new composite key structure
|
|
-- We'll need to update these after the phase tables are updated
|
|
|
|
-- Note: The soaking_id, airdrying_id, cracking_id, shelling_id columns in experiments table
|
|
-- will need to be updated to reference the new composite structure
|
|
-- This will be handled in the seed files update
|