Remove deprecated CSV files and update experiment seeding scripts

- 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.
This commit is contained in:
salirezav
2025-09-28 21:10:50 -04:00
parent 853cec1b13
commit e675423258
28 changed files with 3068 additions and 1457 deletions

View File

@@ -1,634 +0,0 @@
-- Complete Database Schema for USDA Vision Pecan Experiments System
-- This migration creates the entire database schema from scratch
-- Supports both JC Cracker and Meyer Cracker experiments
-- =============================================
-- 1. EXTENSIONS
-- =============================================
-- Enable UUID generation
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Enable password hashing
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
-- =============================================
-- 2. USER MANAGEMENT
-- =============================================
-- Create roles table
CREATE TABLE IF NOT EXISTS public.roles (
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()
);
-- Create user profiles table
CREATE TABLE IF NOT EXISTS public.user_profiles (
id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
email TEXT NOT NULL UNIQUE,
first_name TEXT,
last_name TEXT,
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'inactive', 'suspended')),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Create user roles junction table
CREATE TABLE IF NOT EXISTS public.user_roles (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID NOT NULL REFERENCES public.user_profiles(id) ON DELETE CASCADE,
role_id UUID NOT NULL REFERENCES public.roles(id) ON DELETE CASCADE,
assigned_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
assigned_by UUID REFERENCES public.user_profiles(id),
UNIQUE(user_id, role_id)
);
-- =============================================
-- 3. 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)
);
-- =============================================
-- 4. EXPERIMENT PHASES
-- =============================================
-- Create experiment phases table
CREATE TABLE IF NOT EXISTS public.experiment_phases (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name TEXT NOT NULL UNIQUE,
description TEXT,
has_soaking BOOLEAN NOT NULL DEFAULT false,
has_airdrying BOOLEAN NOT NULL DEFAULT false,
has_cracking BOOLEAN NOT NULL DEFAULT false,
has_shelling BOOLEAN NOT NULL DEFAULT false,
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 at least one phase is selected
CONSTRAINT check_at_least_one_phase
CHECK (has_soaking = true OR has_airdrying = true OR has_cracking = true OR has_shelling = true)
);
-- =============================================
-- 5. EXPERIMENTS
-- =============================================
-- Create experiments table
CREATE TABLE IF NOT EXISTS public.experiments (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_number INTEGER UNIQUE NOT NULL,
reps_required INTEGER NOT NULL CHECK (reps_required > 0),
weight_per_repetition_lbs DOUBLE PRECISION NOT NULL DEFAULT 5.0 CHECK (weight_per_repetition_lbs > 0),
results_status TEXT NOT NULL DEFAULT 'valid' CHECK (results_status IN ('valid', 'invalid')),
completion_status BOOLEAN NOT NULL DEFAULT false,
phase_id UUID REFERENCES public.experiment_phases(id) ON DELETE SET NULL,
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)
);
-- =============================================
-- 6. EXPERIMENT REPETITIONS
-- =============================================
-- Create experiment repetitions table
CREATE TABLE IF NOT EXISTS public.experiment_repetitions (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE,
repetition_number INTEGER NOT NULL CHECK (repetition_number > 0),
status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', '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 unique repetition numbers per experiment
UNIQUE(experiment_id, repetition_number)
);
-- =============================================
-- 7. 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)
);
-- =============================================
-- 8. 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,
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)
);
-- =============================================
-- 9. ADD FOREIGN KEY CONSTRAINTS TO EXPERIMENTS
-- =============================================
-- 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;
-- =============================================
-- 10. CREATE INDEXES FOR PERFORMANCE
-- =============================================
-- Create indexes for better query performance
CREATE INDEX IF NOT EXISTS idx_user_profiles_email ON public.user_profiles(email);
CREATE INDEX IF NOT EXISTS idx_user_roles_user_id ON public.user_roles(user_id);
CREATE INDEX IF NOT EXISTS idx_user_roles_role_id ON public.user_roles(role_id);
CREATE INDEX IF NOT EXISTS idx_experiments_phase_id ON public.experiments(phase_id);
CREATE INDEX IF NOT EXISTS idx_experiments_experiment_number ON public.experiments(experiment_number);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_id ON public.experiment_repetitions(experiment_id);
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);
-- =============================================
-- 11. 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();
-- =============================================
-- 12. 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.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_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;
-- =============================================
-- 13. GRANT PERMISSIONS
-- =============================================
-- Grant permissions for all tables
GRANT ALL ON public.roles TO authenticated;
GRANT ALL ON public.user_profiles TO authenticated;
GRANT ALL ON public.user_roles TO authenticated;
GRANT ALL ON public.machine_types TO authenticated;
GRANT ALL ON public.experiment_phases TO authenticated;
GRANT ALL ON public.experiments TO authenticated;
GRANT ALL ON public.experiment_repetitions 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;
-- =============================================
-- 14. ENABLE ROW LEVEL SECURITY
-- =============================================
-- Enable RLS on all tables
ALTER TABLE public.roles ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.user_profiles ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.user_roles ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.machine_types ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.experiment_phases ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.experiments ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.experiment_repetitions 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;
-- =============================================
-- 15. CREATE RLS POLICIES
-- =============================================
-- Create RLS policies for roles (read-only for all authenticated users)
CREATE POLICY "Roles are viewable by authenticated users" ON public.roles
FOR SELECT USING (auth.role() = 'authenticated');
-- Create RLS policies for user_profiles
CREATE POLICY "User profiles are viewable by authenticated users" ON public.user_profiles
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "User profiles are insertable by authenticated users" ON public.user_profiles
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "User profiles are updatable by authenticated users" ON public.user_profiles
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "User profiles are deletable by authenticated users" ON public.user_profiles
FOR DELETE USING (auth.role() = 'authenticated');
-- Create RLS policies for user_roles
CREATE POLICY "User roles are viewable by authenticated users" ON public.user_roles
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "User roles are insertable by authenticated users" ON public.user_roles
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "User roles are updatable by authenticated users" ON public.user_roles
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "User roles are deletable by authenticated users" ON public.user_roles
FOR DELETE USING (auth.role() = 'authenticated');
-- 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 POLICY "Machine types are insertable by authenticated users" ON public.machine_types
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Machine types are updatable by authenticated users" ON public.machine_types
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "Machine types are deletable by authenticated users" ON public.machine_types
FOR DELETE USING (auth.role() = 'authenticated');
-- Create RLS policies for experiment_phases
CREATE POLICY "Experiment phases are viewable by authenticated users" ON public.experiment_phases
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "Experiment phases are insertable by authenticated users" ON public.experiment_phases
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Experiment phases are updatable by authenticated users" ON public.experiment_phases
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "Experiment phases are deletable by authenticated users" ON public.experiment_phases
FOR DELETE USING (auth.role() = 'authenticated');
-- Create RLS policies for experiments
CREATE POLICY "Experiments are viewable by authenticated users" ON public.experiments
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "Experiments are insertable by authenticated users" ON public.experiments
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Experiments are updatable by authenticated users" ON public.experiments
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "Experiments are deletable by authenticated users" ON public.experiments
FOR DELETE USING (auth.role() = 'authenticated');
-- Create RLS policies for experiment_repetitions
CREATE POLICY "Experiment repetitions are viewable by authenticated users" ON public.experiment_repetitions
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "Experiment repetitions are insertable by authenticated users" ON public.experiment_repetitions
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Experiment repetitions are updatable by authenticated users" ON public.experiment_repetitions
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "Experiment repetitions are deletable by authenticated users" ON public.experiment_repetitions
FOR DELETE USING (auth.role() = 'authenticated');
-- 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');

View File

@@ -0,0 +1,189 @@
-- User Management and Authentication
-- This migration creates user-related tables, roles, and authentication structures
-- =============================================
-- 1. EXTENSIONS
-- =============================================
-- Enable UUID generation
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Enable password hashing
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
-- =============================================
-- 2. USER MANAGEMENT
-- =============================================
-- Create roles table
CREATE TABLE IF NOT EXISTS public.roles (
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()
);
-- Create user profiles table
CREATE TABLE IF NOT EXISTS public.user_profiles (
id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
email TEXT NOT NULL UNIQUE,
first_name TEXT,
last_name TEXT,
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'inactive', 'suspended')),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Create user roles junction table
CREATE TABLE IF NOT EXISTS public.user_roles (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID NOT NULL REFERENCES public.user_profiles(id) ON DELETE CASCADE,
role_id UUID NOT NULL REFERENCES public.roles(id) ON DELETE CASCADE,
assigned_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
assigned_by UUID REFERENCES public.user_profiles(id),
UNIQUE(user_id, role_id)
);
-- =============================================
-- 3. UTILITY FUNCTIONS
-- =============================================
-- Function to handle updated_at timestamp
CREATE OR REPLACE FUNCTION public.handle_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Helper function to get current user's roles
CREATE OR REPLACE FUNCTION public.get_user_roles()
RETURNS TEXT[] AS $$
BEGIN
RETURN ARRAY(
SELECT r.name
FROM public.user_roles ur
JOIN public.roles r ON ur.role_id = r.id
WHERE ur.user_id = auth.uid()
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to get current user's first role (for backward compatibility)
CREATE OR REPLACE FUNCTION public.get_user_role()
RETURNS TEXT AS $$
BEGIN
-- Return the first role found (for backward compatibility)
RETURN (
SELECT r.name
FROM public.user_roles ur
JOIN public.roles r ON ur.role_id = r.id
WHERE ur.user_id = auth.uid()
LIMIT 1
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to check if user is admin
CREATE OR REPLACE FUNCTION public.is_admin()
RETURNS BOOLEAN AS $$
BEGIN
RETURN 'admin' = ANY(public.get_user_roles());
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to check if user has specific role
CREATE OR REPLACE FUNCTION public.has_role(role_name TEXT)
RETURNS BOOLEAN AS $$
BEGIN
RETURN role_name = ANY(public.get_user_roles());
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to check if user can manage experiments
CREATE OR REPLACE FUNCTION public.can_manage_experiments()
RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1
FROM public.user_roles ur
JOIN public.roles r ON ur.role_id = r.id
WHERE ur.user_id = auth.uid()
AND r.name IN ('admin', 'conductor')
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- =============================================
-- 4. INDEXES FOR PERFORMANCE
-- =============================================
CREATE INDEX IF NOT EXISTS idx_user_profiles_email ON public.user_profiles(email);
CREATE INDEX IF NOT EXISTS idx_user_roles_user_id ON public.user_roles(user_id);
CREATE INDEX IF NOT EXISTS idx_user_roles_role_id ON public.user_roles(role_id);
-- =============================================
-- 5. TRIGGERS
-- =============================================
-- Create trigger for updated_at on user_profiles
CREATE TRIGGER set_updated_at_user_profiles
BEFORE UPDATE ON public.user_profiles
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- =============================================
-- 6. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.roles TO authenticated;
GRANT ALL ON public.user_profiles TO authenticated;
GRANT ALL ON public.user_roles TO authenticated;
-- =============================================
-- 7. ENABLE ROW LEVEL SECURITY
-- =============================================
ALTER TABLE public.roles ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.user_profiles ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.user_roles ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 8. CREATE RLS POLICIES
-- =============================================
-- Create RLS policies for roles (read-only for all authenticated users)
CREATE POLICY "Roles are viewable by authenticated users" ON public.roles
FOR SELECT USING (auth.role() = 'authenticated');
-- Create RLS policies for user_profiles
CREATE POLICY "User profiles are viewable by authenticated users" ON public.user_profiles
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "User profiles are insertable by authenticated users" ON public.user_profiles
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "User profiles are updatable by authenticated users" ON public.user_profiles
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "User profiles are deletable by authenticated users" ON public.user_profiles
FOR DELETE USING (auth.role() = 'authenticated');
-- Create RLS policies for user_roles
CREATE POLICY "User roles are viewable by authenticated users" ON public.user_roles
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "User roles are insertable by authenticated users" ON public.user_roles
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "User roles are updatable by authenticated users" ON public.user_roles
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "User roles are deletable by authenticated users" ON public.user_roles
FOR DELETE USING (auth.role() = 'authenticated');

View File

@@ -0,0 +1,115 @@
-- Machine Types and Experiment Phases
-- This migration creates machine types and experiment phase definitions
-- =============================================
-- 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)
);
-- =============================================
-- 2. EXPERIMENT PHASES
-- =============================================
-- Create experiment phases table
CREATE TABLE IF NOT EXISTS public.experiment_phases (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name TEXT NOT NULL UNIQUE,
description TEXT,
has_soaking BOOLEAN NOT NULL DEFAULT false,
has_airdrying BOOLEAN NOT NULL DEFAULT false,
has_cracking BOOLEAN NOT NULL DEFAULT false,
has_shelling BOOLEAN NOT NULL DEFAULT false,
cracking_machine_type_id UUID REFERENCES public.machine_types(id) ON DELETE SET NULL,
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 at least one phase is selected
CONSTRAINT check_at_least_one_phase
CHECK (has_soaking = true OR has_airdrying = true OR has_cracking = true OR has_shelling = true),
-- If has_cracking is true, then cracking_machine_type_id must not be null
CONSTRAINT ck_experiment_phases_machine_required_when_cracking
CHECK ((has_cracking = false) OR (cracking_machine_type_id IS NOT NULL))
);
-- =============================================
-- 3. INDEXES FOR PERFORMANCE
-- =============================================
CREATE INDEX IF NOT EXISTS idx_machine_types_name ON public.machine_types(name);
CREATE INDEX IF NOT EXISTS idx_experiment_phases_name ON public.experiment_phases(name);
CREATE INDEX IF NOT EXISTS idx_experiment_phases_cracking_machine_type_id ON public.experiment_phases(cracking_machine_type_id);
-- =============================================
-- 4. TRIGGERS
-- =============================================
-- Create trigger for updated_at on machine_types
CREATE TRIGGER set_updated_at_machine_types
BEFORE UPDATE ON public.machine_types
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- Create trigger for updated_at on experiment_phases
CREATE TRIGGER set_updated_at_experiment_phases
BEFORE UPDATE ON public.experiment_phases
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- =============================================
-- 5. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.machine_types TO authenticated;
GRANT ALL ON public.experiment_phases TO authenticated;
-- =============================================
-- 6. ENABLE ROW LEVEL SECURITY
-- =============================================
ALTER TABLE public.machine_types ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.experiment_phases ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 7. CREATE RLS POLICIES
-- =============================================
-- Create RLS policies for machine_types
CREATE POLICY "Machine types are viewable by authenticated users" ON public.machine_types
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "Machine types are insertable by authenticated users" ON public.machine_types
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Machine types are updatable by authenticated users" ON public.machine_types
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "Machine types are deletable by authenticated users" ON public.machine_types
FOR DELETE USING (auth.role() = 'authenticated');
-- Create RLS policies for experiment_phases
CREATE POLICY "Experiment phases are viewable by authenticated users" ON public.experiment_phases
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "Experiment phases are insertable by authenticated users" ON public.experiment_phases
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Experiment phases are updatable by authenticated users" ON public.experiment_phases
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "Experiment phases are deletable by authenticated users" ON public.experiment_phases
FOR DELETE USING (auth.role() = 'authenticated');

View File

@@ -0,0 +1,120 @@
-- Experiments and Repetitions
-- This migration creates the experiments and experiment repetitions tables with composite primary key
-- =============================================
-- 1. EXPERIMENTS
-- =============================================
-- Create experiments table with composite primary key (experiment_number, phase_id)
CREATE TABLE IF NOT EXISTS public.experiments (
id UUID DEFAULT uuid_generate_v4(),
experiment_number INTEGER NOT NULL,
reps_required INTEGER NOT NULL CHECK (reps_required > 0),
weight_per_repetition_lbs DOUBLE PRECISION NOT NULL DEFAULT 5.0 CHECK (weight_per_repetition_lbs > 0),
results_status TEXT NOT NULL DEFAULT 'valid' CHECK (results_status IN ('valid', 'invalid')),
completion_status BOOLEAN NOT NULL DEFAULT false,
phase_id UUID NOT NULL REFERENCES public.experiment_phases(id) ON DELETE SET NULL,
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),
-- Composite primary key allows each phase to have its own experiment numbering starting from 1
PRIMARY KEY (experiment_number, phase_id)
);
-- =============================================
-- 2. EXPERIMENT REPETITIONS
-- =============================================
-- Create experiment repetitions table
CREATE TABLE IF NOT EXISTS public.experiment_repetitions (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_number INTEGER NOT NULL,
experiment_phase_id UUID NOT NULL,
repetition_number INTEGER NOT NULL CHECK (repetition_number > 0),
status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', '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),
-- Foreign key to experiments using composite key
FOREIGN KEY (experiment_number, experiment_phase_id)
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE,
-- Ensure unique repetition numbers per experiment
UNIQUE(experiment_number, experiment_phase_id, repetition_number)
);
-- =============================================
-- 3. INDEXES FOR PERFORMANCE
-- =============================================
CREATE INDEX IF NOT EXISTS idx_experiments_phase_id ON public.experiments(phase_id);
CREATE INDEX IF NOT EXISTS idx_experiments_experiment_number ON public.experiments(experiment_number);
CREATE INDEX IF NOT EXISTS idx_experiments_created_by ON public.experiments(created_by);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_composite ON public.experiment_repetitions(experiment_number, experiment_phase_id);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_created_by ON public.experiment_repetitions(created_by);
-- =============================================
-- 4. TRIGGERS
-- =============================================
-- Create trigger for updated_at on experiments
CREATE TRIGGER set_updated_at_experiments
BEFORE UPDATE ON public.experiments
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- Create trigger for updated_at on experiment_repetitions
CREATE TRIGGER set_updated_at_experiment_repetitions
BEFORE UPDATE ON public.experiment_repetitions
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- =============================================
-- 5. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.experiments TO authenticated;
GRANT ALL ON public.experiment_repetitions TO authenticated;
-- =============================================
-- 6. ENABLE ROW LEVEL SECURITY
-- =============================================
ALTER TABLE public.experiments ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.experiment_repetitions ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 7. CREATE RLS POLICIES
-- =============================================
-- Create RLS policies for experiments
CREATE POLICY "Experiments are viewable by authenticated users" ON public.experiments
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "Experiments are insertable by authenticated users" ON public.experiments
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Experiments are updatable by authenticated users" ON public.experiments
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "Experiments are deletable by authenticated users" ON public.experiments
FOR DELETE USING (auth.role() = 'authenticated');
-- Create RLS policies for experiment_repetitions
CREATE POLICY "Experiment repetitions are viewable by authenticated users" ON public.experiment_repetitions
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "Experiment repetitions are insertable by authenticated users" ON public.experiment_repetitions
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Experiment repetitions are updatable by authenticated users" ON public.experiment_repetitions
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "Experiment repetitions are deletable by authenticated users" ON public.experiment_repetitions
FOR DELETE USING (auth.role() = 'authenticated');

View File

@@ -0,0 +1,403 @@
-- 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_number INTEGER NOT NULL,
experiment_phase_id UUID NOT NULL,
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),
-- Foreign key to experiments using composite key
FOREIGN KEY (experiment_number, experiment_phase_id)
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE,
-- Ensure only one soaking per experiment or repetition
CONSTRAINT unique_soaking_per_experiment UNIQUE (experiment_number, experiment_phase_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_number INTEGER NOT NULL,
experiment_phase_id UUID NOT NULL,
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),
-- Foreign key to experiments using composite key
FOREIGN KEY (experiment_number, experiment_phase_id)
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE,
-- Ensure only one airdrying per experiment or repetition
CONSTRAINT unique_airdrying_per_experiment UNIQUE (experiment_number, experiment_phase_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_number INTEGER NOT NULL,
experiment_phase_id UUID NOT NULL,
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),
-- Foreign key to experiments using composite key
FOREIGN KEY (experiment_number, experiment_phase_id)
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE,
-- Ensure only one cracking per experiment or repetition
CONSTRAINT unique_cracking_per_experiment UNIQUE (experiment_number, experiment_phase_id),
CONSTRAINT unique_cracking_per_repetition UNIQUE (repetition_id)
);
-- =============================================
-- 4. SHELLING TABLE
-- =============================================
-- Create shelling table
CREATE TABLE IF NOT EXISTS public.shelling (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_number INTEGER NOT NULL,
experiment_phase_id UUID NOT NULL,
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),
-- Foreign key to experiments using composite key
FOREIGN KEY (experiment_number, experiment_phase_id)
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE,
-- Ensure only one shelling per experiment or repetition
CONSTRAINT unique_shelling_per_experiment UNIQUE (experiment_number, experiment_phase_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(),
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,
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)
);
-- =============================================
-- 6. ADD FOREIGN KEY CONSTRAINTS TO EXPERIMENTS
-- =============================================
-- 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. INDEXES FOR PERFORMANCE
-- =============================================
-- Create composite indexes for phase tables
CREATE INDEX IF NOT EXISTS idx_soaking_experiment_composite ON public.soaking(experiment_number, experiment_phase_id);
CREATE INDEX IF NOT EXISTS idx_airdrying_experiment_composite ON public.airdrying(experiment_number, experiment_phase_id);
CREATE INDEX IF NOT EXISTS idx_cracking_experiment_composite ON public.cracking(experiment_number, experiment_phase_id);
CREATE INDEX IF NOT EXISTS idx_shelling_experiment_composite ON public.shelling(experiment_number, experiment_phase_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_number = NEW.experiment_number
AND s.experiment_phase_id = NEW.experiment_phase_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_number = NEW.experiment_number
AND a.experiment_phase_id = NEW.experiment_phase_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');

View File

@@ -1,5 +1,5 @@
-- Add Conductor Availability and Experiment Phase Assignment Tables
-- This migration adds tables for conductor availability management and future experiment scheduling
-- Conductor Availability and Scheduling
-- This migration creates tables for conductor availability management and experiment scheduling
-- =============================================
-- 1. CONDUCTOR AVAILABILITY TABLE
@@ -25,13 +25,14 @@ CREATE TABLE IF NOT EXISTS public.conductor_availability (
);
-- =============================================
-- 2. EXPERIMENT PHASE ASSIGNMENTS TABLE (Future Scheduling)
-- 2. EXPERIMENT PHASE ASSIGNMENTS TABLE
-- =============================================
-- Create experiment_phase_assignments table for scheduling conductors to experiment phases
CREATE TABLE IF NOT EXISTS public.experiment_phase_assignments (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE,
experiment_number INTEGER NOT NULL,
experiment_phase_id UUID NOT NULL,
repetition_id UUID NOT NULL REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE,
conductor_id UUID NOT NULL REFERENCES public.user_profiles(id) ON DELETE CASCADE,
phase_name TEXT NOT NULL CHECK (phase_name IN ('pre-soaking', 'air-drying', 'cracking', 'shelling')),
@@ -43,6 +44,10 @@ CREATE TABLE IF NOT EXISTS public.experiment_phase_assignments (
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by UUID NOT NULL REFERENCES public.user_profiles(id),
-- Foreign key to experiments using composite key
FOREIGN KEY (experiment_number, experiment_phase_id)
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE,
-- Ensure scheduled_end_time is after scheduled_start_time
CONSTRAINT valid_scheduled_time_range CHECK (scheduled_end_time > scheduled_start_time),
@@ -63,7 +68,7 @@ CREATE INDEX IF NOT EXISTS idx_conductor_availability_created_by ON public.condu
CREATE INDEX IF NOT EXISTS idx_conductor_availability_time_range ON public.conductor_availability(available_from, available_to);
-- Experiment phase assignments indexes
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_experiment_id ON public.experiment_phase_assignments(experiment_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_experiment_composite ON public.experiment_phase_assignments(experiment_number, experiment_phase_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_repetition_id ON public.experiment_phase_assignments(repetition_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_conductor_id ON public.experiment_phase_assignments(conductor_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_phase_name ON public.experiment_phase_assignments(phase_name);
@@ -72,78 +77,7 @@ CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_scheduled_start ON p
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_created_by ON public.experiment_phase_assignments(created_by);
-- =============================================
-- 4. UTILITY FUNCTIONS
-- =============================================
-- Function to handle updated_at timestamp
CREATE OR REPLACE FUNCTION public.handle_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Helper function to get current user's roles
CREATE OR REPLACE FUNCTION public.get_user_roles()
RETURNS TEXT[] AS $$
BEGIN
RETURN ARRAY(
SELECT r.name
FROM public.user_roles ur
JOIN public.roles r ON ur.role_id = r.id
WHERE ur.user_id = auth.uid()
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to get current user's first role (for backward compatibility)
CREATE OR REPLACE FUNCTION public.get_user_role()
RETURNS TEXT AS $$
BEGIN
-- Return the first role found (for backward compatibility)
RETURN (
SELECT r.name
FROM public.user_roles ur
JOIN public.roles r ON ur.role_id = r.id
WHERE ur.user_id = auth.uid()
LIMIT 1
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to check if user is admin
CREATE OR REPLACE FUNCTION public.is_admin()
RETURNS BOOLEAN AS $$
BEGIN
RETURN 'admin' = ANY(public.get_user_roles());
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to check if user has specific role
CREATE OR REPLACE FUNCTION public.has_role(role_name TEXT)
RETURNS BOOLEAN AS $$
BEGIN
RETURN role_name = ANY(public.get_user_roles());
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to check if user can manage experiments
CREATE OR REPLACE FUNCTION public.can_manage_experiments()
RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1
FROM public.user_roles ur
JOIN public.roles r ON ur.role_id = r.id
WHERE ur.user_id = auth.uid()
AND r.name IN ('admin', 'conductor')
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- =============================================
-- 5. FUNCTIONS FOR OVERLAP PREVENTION
-- 4. FUNCTIONS FOR OVERLAP PREVENTION
-- =============================================
-- Function to check for overlapping availabilities
@@ -177,85 +111,8 @@ BEGIN
END;
$$ LANGUAGE plpgsql;
-- Function to automatically adjust overlapping availabilities (alternative approach)
CREATE OR REPLACE FUNCTION public.adjust_overlapping_availability()
RETURNS TRIGGER AS $$
DECLARE
overlapping_record RECORD;
BEGIN
-- Find overlapping availabilities and adjust them
FOR overlapping_record IN
SELECT id, available_from, available_to
FROM public.conductor_availability
WHERE user_id = NEW.user_id
AND id != COALESCE(NEW.id, '00000000-0000-0000-0000-000000000000'::UUID)
AND status = 'active'
AND (
(NEW.available_from >= available_from AND NEW.available_from < available_to) OR
(NEW.available_to > available_from AND NEW.available_to <= available_to) OR
(NEW.available_from <= available_from AND NEW.available_to >= available_to) OR
(available_from <= NEW.available_from AND available_to >= NEW.available_to)
)
LOOP
-- Adjust the overlapping record to end where the new one starts
IF overlapping_record.available_from < NEW.available_from AND overlapping_record.available_to > NEW.available_from THEN
UPDATE public.conductor_availability
SET available_to = NEW.available_from,
updated_at = NOW()
WHERE id = overlapping_record.id;
END IF;
-- If the overlapping record starts after the new one, adjust it to start where the new one ends
IF overlapping_record.available_from < NEW.available_to AND overlapping_record.available_to > NEW.available_to THEN
UPDATE public.conductor_availability
SET available_from = NEW.available_to,
updated_at = NOW()
WHERE id = overlapping_record.id;
END IF;
-- If the overlapping record is completely contained within the new one, cancel it
IF overlapping_record.available_from >= NEW.available_from AND overlapping_record.available_to <= NEW.available_to THEN
UPDATE public.conductor_availability
SET status = 'cancelled',
updated_at = NOW()
WHERE id = overlapping_record.id;
END IF;
END LOOP;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- =============================================
-- 6. TRIGGERS
-- =============================================
-- Create trigger for updated_at on conductor_availability
CREATE TRIGGER set_updated_at_conductor_availability
BEFORE UPDATE ON public.conductor_availability
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- Create trigger for updated_at on experiment_phase_assignments
CREATE TRIGGER set_updated_at_experiment_phase_assignments
BEFORE UPDATE ON public.experiment_phase_assignments
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- Create trigger to prevent overlapping availabilities (strict approach)
CREATE TRIGGER trigger_check_availability_overlap
BEFORE INSERT OR UPDATE ON public.conductor_availability
FOR EACH ROW
EXECUTE FUNCTION public.check_availability_overlap();
-- Alternative trigger to automatically adjust overlapping availabilities (uncomment if preferred)
-- CREATE TRIGGER trigger_adjust_overlapping_availability
-- BEFORE INSERT OR UPDATE ON public.conductor_availability
-- FOR EACH ROW
-- EXECUTE FUNCTION public.adjust_overlapping_availability();
-- =============================================
-- 6. HELPER FUNCTIONS
-- 5. HELPER FUNCTIONS
-- =============================================
-- Function to get available conductors for a specific time range
@@ -310,13 +167,45 @@ END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- =============================================
-- 8. ROW LEVEL SECURITY (RLS)
-- 6. TRIGGERS
-- =============================================
-- Create trigger for updated_at on conductor_availability
CREATE TRIGGER set_updated_at_conductor_availability
BEFORE UPDATE ON public.conductor_availability
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- Create trigger for updated_at on experiment_phase_assignments
CREATE TRIGGER set_updated_at_experiment_phase_assignments
BEFORE UPDATE ON public.experiment_phase_assignments
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- Create trigger to prevent overlapping availabilities
CREATE TRIGGER trigger_check_availability_overlap
BEFORE INSERT OR UPDATE ON public.conductor_availability
FOR EACH ROW
EXECUTE FUNCTION public.check_availability_overlap();
-- =============================================
-- 7. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.conductor_availability TO authenticated;
GRANT ALL ON public.experiment_phase_assignments TO authenticated;
-- =============================================
-- 8. ENABLE ROW LEVEL SECURITY
-- =============================================
-- Enable RLS on new tables
ALTER TABLE public.conductor_availability ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.experiment_phase_assignments ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 9. CREATE RLS POLICIES
-- =============================================
-- Conductor availability policies
CREATE POLICY "conductor_availability_select_policy" ON public.conductor_availability
FOR SELECT
@@ -392,7 +281,7 @@ CREATE POLICY "experiment_phase_assignments_delete_policy" ON public.experiment_
);
-- =============================================
-- 8. COMMENTS FOR DOCUMENTATION
-- 10. COMMENTS FOR DOCUMENTATION
-- =============================================
COMMENT ON TABLE public.conductor_availability IS 'Stores conductor availability windows for experiment scheduling';
@@ -410,3 +299,5 @@ COMMENT ON COLUMN public.experiment_phase_assignments.status IS 'Current status
COMMENT ON COLUMN public.experiment_phase_assignments.notes IS 'Optional notes about the assignment';

View File

@@ -0,0 +1,216 @@
-- Views and Final Setup
-- This migration creates views for easier querying and finalizes the database setup
-- =============================================
-- 1. 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_hours,
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.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_hours,
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;
-- View for conductor assignments with experiment details
CREATE OR REPLACE VIEW public.conductor_assignments_with_details AS
SELECT
epa.id,
epa.experiment_number,
epa.experiment_phase_id,
epa.repetition_id,
epa.conductor_id,
epa.phase_name,
epa.scheduled_start_time,
epa.scheduled_end_time,
epa.status,
epa.notes,
epa.created_at,
epa.updated_at,
epa.created_by,
e.reps_required,
e.weight_per_repetition_lbs,
ep.name as experiment_phase_name,
ep.description as phase_description,
up.email as conductor_email,
up.first_name as conductor_first_name,
up.last_name as conductor_last_name,
er.repetition_number,
er.status as repetition_status
FROM public.experiment_phase_assignments epa
JOIN public.experiments e ON epa.experiment_number = e.experiment_number AND epa.experiment_phase_id = e.phase_id
JOIN public.experiment_phases ep ON e.phase_id = ep.id
JOIN public.user_profiles up ON epa.conductor_id = up.id
JOIN public.experiment_repetitions er ON epa.repetition_id = er.id;
-- View for available conductors with their roles
CREATE OR REPLACE VIEW public.available_conductors AS
SELECT
ca.*,
up.email,
up.first_name,
up.last_name,
r.name as role_name
FROM public.conductor_availability ca
JOIN public.user_profiles up ON ca.user_id = up.id
JOIN public.user_roles ur ON up.id = ur.user_id
JOIN public.roles r ON ur.role_id = r.id
WHERE ca.status = 'active'
AND r.name = 'conductor';
-- =============================================
-- 2. GRANT PERMISSIONS FOR VIEWS
-- =============================================
GRANT SELECT ON public.experiments_with_phases TO authenticated;
GRANT SELECT ON public.repetitions_with_phases TO authenticated;
GRANT SELECT ON public.conductor_assignments_with_details TO authenticated;
GRANT SELECT ON public.available_conductors TO authenticated;
-- =============================================
-- 3. FINAL COMMENTS FOR DOCUMENTATION
-- =============================================
COMMENT ON VIEW public.experiments_with_phases IS 'Comprehensive view of experiments with all phase information and timing details';
COMMENT ON VIEW public.repetitions_with_phases IS 'View of experiment repetitions with associated phase data';
COMMENT ON VIEW public.conductor_assignments_with_details IS 'Detailed view of conductor assignments with experiment and conductor information';
COMMENT ON VIEW public.available_conductors IS 'View of currently available conductors with their profile information';
-- =============================================
-- 4. CREATE SAMPLE DATA FUNCTIONS (OPTIONAL)
-- =============================================
-- Function to create sample roles
CREATE OR REPLACE FUNCTION public.create_sample_roles()
RETURNS VOID AS $$
BEGIN
INSERT INTO public.roles (name, description) VALUES
('admin', 'System administrator with full access'),
('conductor', 'Experiment conductor with limited access'),
('researcher', 'Research staff with read-only access')
ON CONFLICT (name) DO NOTHING;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Function to create sample machine types
CREATE OR REPLACE FUNCTION public.create_sample_machine_types()
RETURNS VOID AS $$
BEGIN
INSERT INTO public.machine_types (name, description, created_by) VALUES
('JC Cracker', 'Johnson Cracker machine for pecan shelling', (SELECT id FROM public.user_profiles LIMIT 1)),
('Meyer Cracker', 'Meyer Cracker machine for pecan shelling', (SELECT id FROM public.user_profiles LIMIT 1))
ON CONFLICT (name) DO NOTHING;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Function to create sample experiment phases
CREATE OR REPLACE FUNCTION public.create_sample_experiment_phases()
RETURNS VOID AS $$
DECLARE
jc_cracker_id UUID;
meyer_cracker_id UUID;
BEGIN
-- Get machine type IDs
SELECT id INTO jc_cracker_id FROM public.machine_types WHERE name = 'JC Cracker';
SELECT id INTO meyer_cracker_id FROM public.machine_types WHERE name = 'Meyer Cracker';
INSERT INTO public.experiment_phases (name, description, has_soaking, has_airdrying, has_cracking, has_shelling, cracking_machine_type_id, created_by) VALUES
('Full Process - JC Cracker', 'Complete pecan processing with JC Cracker', true, true, true, true, jc_cracker_id, (SELECT id FROM public.user_profiles LIMIT 1)),
('Full Process - Meyer Cracker', 'Complete pecan processing with Meyer Cracker', true, true, true, true, meyer_cracker_id, (SELECT id FROM public.user_profiles LIMIT 1)),
('Cracking Only - JC Cracker', 'JC Cracker cracking process only', false, false, true, false, jc_cracker_id, (SELECT id FROM public.user_profiles LIMIT 1)),
('Cracking Only - Meyer Cracker', 'Meyer Cracker cracking process only', false, false, true, false, meyer_cracker_id, (SELECT id FROM public.user_profiles LIMIT 1))
ON CONFLICT (name) DO NOTHING;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- =============================================
-- 5. GRANT PERMISSIONS FOR SAMPLE DATA FUNCTIONS
-- =============================================
GRANT EXECUTE ON FUNCTION public.create_sample_roles() TO authenticated;
GRANT EXECUTE ON FUNCTION public.create_sample_machine_types() TO authenticated;
GRANT EXECUTE ON FUNCTION public.create_sample_experiment_phases() TO authenticated;

View File

@@ -1,185 +0,0 @@
-- 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

View File

@@ -0,0 +1,133 @@
-- 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;

View File

@@ -1,13 +0,0 @@
-- Convert soaking duration to hours instead of minutes
-- 1) Rename column
ALTER TABLE public.soaking RENAME COLUMN soaking_duration_minutes TO soaking_duration_hours;
-- 2) Change type to double precision to allow fractional hours
ALTER TABLE public.soaking ALTER COLUMN soaking_duration_hours TYPE DOUBLE PRECISION USING soaking_duration_hours::double precision;
-- 3) Convert existing data (currently minutes) to hours
UPDATE public.soaking SET soaking_duration_hours = soaking_duration_hours / 60.0;
-- 4) Ensure CHECK constraint (> 0)
ALTER TABLE public.soaking DROP CONSTRAINT IF EXISTS soaking_soaking_duration_minutes_check;
ALTER TABLE public.soaking ADD CONSTRAINT soaking_soaking_duration_hours_check CHECK (soaking_duration_hours > 0);

View File

@@ -1,27 +0,0 @@
-- Migration: Add cracking_machine_type_id to experiment_phases
-- Adds optional reference to machine_types so a phase can specify the cracking machine
BEGIN;
-- 1) Add column (nullable to avoid breaking existing data)
ALTER TABLE public.experiment_phases
ADD COLUMN IF NOT EXISTS cracking_machine_type_id UUID NULL;
-- 2) Add foreign key to machine_types
ALTER TABLE public.experiment_phases
ADD CONSTRAINT fk_experiment_phases_cracking_machine_type
FOREIGN KEY (cracking_machine_type_id)
REFERENCES public.machine_types(id)
ON DELETE SET NULL;
-- 3) Optional: index for lookup/filtering
CREATE INDEX IF NOT EXISTS idx_experiment_phases_cracking_machine_type_id
ON public.experiment_phases (cracking_machine_type_id);
COMMIT;

View File

@@ -1,32 +0,0 @@
-- Migration: Require cracking_machine_type_id when has_cracking is true
BEGIN;
-- Drop existing constraint if it exists (for re-runs)
DO $$
BEGIN
IF EXISTS (
SELECT 1 FROM pg_constraint c
JOIN pg_class t ON c.conrelid = t.oid
WHERE t.relname = 'experiment_phases'
AND c.conname = 'ck_experiment_phases_machine_required_when_cracking'
) THEN
ALTER TABLE public.experiment_phases
DROP CONSTRAINT ck_experiment_phases_machine_required_when_cracking;
END IF;
END $$;
-- Add check: if has_cracking then cracking_machine_type_id must not be null
ALTER TABLE public.experiment_phases
ADD CONSTRAINT ck_experiment_phases_machine_required_when_cracking
CHECK (
(has_cracking = false) OR (cracking_machine_type_id IS NOT NULL)
);
COMMIT;

View File

@@ -0,0 +1,44 @@
-- Change experiments primary key to (id, experiment_number)
-- Preserve uniqueness on (experiment_number, phase_id) for legacy FKs
-- Ensure experiments.id is unique so existing FKs to id remain valid
BEGIN;
-- 1) Ensure experiments.id is unique for FKs to reference
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_constraint WHERE conname = 'experiments_id_key'
) THEN
ALTER TABLE public.experiments
ADD CONSTRAINT experiments_id_key UNIQUE (id);
END IF;
END $$;
-- 2) Ensure (experiment_number, phase_id) remains unique before dropping PK
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_constraint WHERE conname = 'experiments_experiment_number_phase_id_key'
) THEN
ALTER TABLE public.experiments
ADD CONSTRAINT experiments_experiment_number_phase_id_key UNIQUE (experiment_number, phase_id);
END IF;
END $$;
-- 3) Do NOT drop the existing primary key because dependent FKs reference it.
-- Instead, add a UNIQUE constraint on (id, experiment_number) to satisfy
-- application-level requirements without breaking dependencies.
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_constraint WHERE conname = 'experiments_id_experiment_number_key'
) THEN
ALTER TABLE public.experiments
ADD CONSTRAINT experiments_id_experiment_number_key UNIQUE (id, experiment_number);
END IF;
END $$;
COMMIT;

View File

@@ -0,0 +1,111 @@
-- Align experiment_repetitions schema with application expectations
-- Adds experiment_id and scheduled_date, maintains existing data, and updates constraints
-- 1) Add columns if missing and remove NOT NULL constraints from old columns
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_schema = 'public' AND table_name = 'experiment_repetitions' AND column_name = 'experiment_id'
) THEN
ALTER TABLE public.experiment_repetitions
ADD COLUMN experiment_id UUID;
END IF;
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_schema = 'public' AND table_name = 'experiment_repetitions' AND column_name = 'scheduled_date'
) THEN
ALTER TABLE public.experiment_repetitions
ADD COLUMN scheduled_date TIMESTAMPTZ NULL;
END IF;
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_schema = 'public' AND table_name = 'experiment_repetitions' AND column_name = 'completion_status'
) THEN
ALTER TABLE public.experiment_repetitions
ADD COLUMN completion_status BOOLEAN NOT NULL DEFAULT false;
END IF;
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_schema = 'public' AND table_name = 'experiment_repetitions' AND column_name = 'is_locked'
) THEN
ALTER TABLE public.experiment_repetitions
ADD COLUMN is_locked BOOLEAN NOT NULL DEFAULT false,
ADD COLUMN locked_at TIMESTAMPTZ NULL,
ADD COLUMN locked_by UUID NULL REFERENCES public.user_profiles(id);
END IF;
-- Remove NOT NULL constraints from old columns to allow new data insertion
ALTER TABLE public.experiment_repetitions ALTER COLUMN experiment_number DROP NOT NULL;
ALTER TABLE public.experiment_repetitions ALTER COLUMN experiment_phase_id DROP NOT NULL;
END $$;
-- 2) Backfill experiment_id by joining on (experiment_number, experiment_phase_id) -> experiments(id)
UPDATE public.experiment_repetitions er
SET experiment_id = e.id
FROM public.experiments e
WHERE er.experiment_id IS NULL
AND e.experiment_number = er.experiment_number
AND e.phase_id = er.experiment_phase_id;
-- 3) Create trigger to auto-populate experiment_id for inserts
CREATE OR REPLACE FUNCTION public.set_experiment_id_on_repetition()
RETURNS TRIGGER AS $func$
BEGIN
IF NEW.experiment_id IS NULL THEN
SELECT e.id INTO NEW.experiment_id
FROM public.experiments e
WHERE e.experiment_number = NEW.experiment_number
AND e.phase_id = NEW.experiment_phase_id;
-- If still NULL, raise an error with helpful message
IF NEW.experiment_id IS NULL THEN
RAISE EXCEPTION 'Could not find experiment with experiment_number=% and phase_id=%',
NEW.experiment_number, NEW.experiment_phase_id;
END IF;
END IF;
RETURN NEW;
END;
$func$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS trg_set_experiment_id_on_repetition ON public.experiment_repetitions;
CREATE TRIGGER trg_set_experiment_id_on_repetition
BEFORE INSERT OR UPDATE OF experiment_number, experiment_phase_id ON public.experiment_repetitions
FOR EACH ROW
EXECUTE FUNCTION public.set_experiment_id_on_repetition();
-- 4) Add FK and not null once backfilled and trigger is in place
ALTER TABLE public.experiment_repetitions
ADD CONSTRAINT experiment_repetitions_experiment_id_fkey
FOREIGN KEY (experiment_id) REFERENCES public.experiments(id) ON DELETE CASCADE;
ALTER TABLE public.experiment_repetitions
ALTER COLUMN experiment_id SET NOT NULL;
-- 5) Create indexes to support queries used in app
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_id ON public.experiment_repetitions(experiment_id);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_repetition_number ON public.experiment_repetitions(repetition_number);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_scheduled_date ON public.experiment_repetitions(scheduled_date);
-- 6) Maintain uniqueness: unique repetition_number per experiment_id
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_constraint
WHERE conname = 'uniq_experiment_repetition_number_per_experiment_id'
) THEN
ALTER TABLE public.experiment_repetitions
ADD CONSTRAINT uniq_experiment_repetition_number_per_experiment_id
UNIQUE (experiment_id, repetition_number);
END IF;
END $$;
-- 6) Optional: keep legacy uniqueness on (experiment_number, experiment_phase_id, repetition_number) if desired
-- This keeps backward compatibility with any existing references
-- 7) RLS already enabled; no change to policies necessary for added columns

View File

@@ -0,0 +1,235 @@
-- Fix phase tables to use experiment_id instead of composite key
-- This aligns the schema with application expectations
BEGIN;
-- 1) Add experiment_id column to all phase tables and remove NOT NULL constraints from old columns
DO $$
BEGIN
-- Soaking table
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_schema = 'public' AND table_name = 'soaking' AND column_name = 'experiment_id'
) THEN
ALTER TABLE public.soaking ADD COLUMN experiment_id UUID;
END IF;
-- Remove NOT NULL constraints from old columns to allow new data insertion
ALTER TABLE public.soaking ALTER COLUMN experiment_number DROP NOT NULL;
ALTER TABLE public.soaking ALTER COLUMN experiment_phase_id DROP NOT NULL;
-- Airdrying table
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_schema = 'public' AND table_name = 'airdrying' AND column_name = 'experiment_id'
) THEN
ALTER TABLE public.airdrying ADD COLUMN experiment_id UUID;
END IF;
ALTER TABLE public.airdrying ALTER COLUMN experiment_number DROP NOT NULL;
ALTER TABLE public.airdrying ALTER COLUMN experiment_phase_id DROP NOT NULL;
-- Cracking table
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_schema = 'public' AND table_name = 'cracking' AND column_name = 'experiment_id'
) THEN
ALTER TABLE public.cracking ADD COLUMN experiment_id UUID;
END IF;
ALTER TABLE public.cracking ALTER COLUMN experiment_number DROP NOT NULL;
ALTER TABLE public.cracking ALTER COLUMN experiment_phase_id DROP NOT NULL;
-- Shelling table
IF NOT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_schema = 'public' AND table_name = 'shelling' AND column_name = 'experiment_id'
) THEN
ALTER TABLE public.shelling ADD COLUMN experiment_id UUID;
END IF;
ALTER TABLE public.shelling ALTER COLUMN experiment_number DROP NOT NULL;
ALTER TABLE public.shelling ALTER COLUMN experiment_phase_id DROP NOT NULL;
END $$;
-- 2) Backfill experiment_id from composite key for all phase tables (only if old data exists)
-- This migration is designed to work with existing data that has the old schema
-- For fresh data, the seed files will populate experiment_id directly
DO $$
BEGIN
-- Only backfill if there are records with the old schema (experiment_number is NOT NULL)
-- and experiment_id is NULL (meaning they haven't been migrated yet)
IF EXISTS (SELECT 1 FROM public.soaking WHERE experiment_id IS NULL AND experiment_number IS NOT NULL) THEN
UPDATE public.soaking s
SET experiment_id = e.id
FROM public.experiments e
WHERE s.experiment_id IS NULL
AND e.experiment_number = s.experiment_number
AND e.phase_id = s.experiment_phase_id;
END IF;
IF EXISTS (SELECT 1 FROM public.airdrying WHERE experiment_id IS NULL AND experiment_number IS NOT NULL) THEN
UPDATE public.airdrying a
SET experiment_id = e.id
FROM public.experiments e
WHERE a.experiment_id IS NULL
AND e.experiment_number = a.experiment_number
AND e.phase_id = a.experiment_phase_id;
END IF;
IF EXISTS (SELECT 1 FROM public.cracking WHERE experiment_id IS NULL AND experiment_number IS NOT NULL) THEN
UPDATE public.cracking c
SET experiment_id = e.id
FROM public.experiments e
WHERE c.experiment_id IS NULL
AND e.experiment_number = c.experiment_number
AND e.phase_id = c.experiment_phase_id;
END IF;
IF EXISTS (SELECT 1 FROM public.shelling WHERE experiment_id IS NULL AND experiment_number IS NOT NULL) THEN
UPDATE public.shelling s
SET experiment_id = e.id
FROM public.experiments e
WHERE s.experiment_id IS NULL
AND e.experiment_number = s.experiment_number
AND e.phase_id = s.experiment_phase_id;
END IF;
END $$;
-- 3) Add foreign key constraints to experiments(id)
ALTER TABLE public.soaking
ADD CONSTRAINT soaking_experiment_id_fkey
FOREIGN KEY (experiment_id) REFERENCES public.experiments(id) ON DELETE CASCADE;
ALTER TABLE public.airdrying
ADD CONSTRAINT airdrying_experiment_id_fkey
FOREIGN KEY (experiment_id) REFERENCES public.experiments(id) ON DELETE CASCADE;
ALTER TABLE public.cracking
ADD CONSTRAINT cracking_experiment_id_fkey
FOREIGN KEY (experiment_id) REFERENCES public.experiments(id) ON DELETE CASCADE;
ALTER TABLE public.shelling
ADD CONSTRAINT shelling_experiment_id_fkey
FOREIGN KEY (experiment_id) REFERENCES public.experiments(id) ON DELETE CASCADE;
-- 4) Create triggers to auto-populate experiment_id for phase tables
CREATE OR REPLACE FUNCTION public.set_experiment_id_on_soaking()
RETURNS TRIGGER AS $func$
BEGIN
IF NEW.experiment_id IS NULL THEN
SELECT e.id INTO NEW.experiment_id
FROM public.experiments e
WHERE e.experiment_number = NEW.experiment_number
AND e.phase_id = NEW.experiment_phase_id;
END IF;
RETURN NEW;
END;
$func$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION public.set_experiment_id_on_airdrying()
RETURNS TRIGGER AS $func$
BEGIN
IF NEW.experiment_id IS NULL THEN
SELECT e.id INTO NEW.experiment_id
FROM public.experiments e
WHERE e.experiment_number = NEW.experiment_number
AND e.phase_id = NEW.experiment_phase_id;
END IF;
RETURN NEW;
END;
$func$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION public.set_experiment_id_on_cracking()
RETURNS TRIGGER AS $func$
BEGIN
IF NEW.experiment_id IS NULL THEN
SELECT e.id INTO NEW.experiment_id
FROM public.experiments e
WHERE e.experiment_number = NEW.experiment_number
AND e.phase_id = NEW.experiment_phase_id;
END IF;
RETURN NEW;
END;
$func$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION public.set_experiment_id_on_shelling()
RETURNS TRIGGER AS $func$
BEGIN
IF NEW.experiment_id IS NULL THEN
SELECT e.id INTO NEW.experiment_id
FROM public.experiments e
WHERE e.experiment_number = NEW.experiment_number
AND e.phase_id = NEW.experiment_phase_id;
END IF;
RETURN NEW;
END;
$func$ LANGUAGE plpgsql;
-- Create triggers
DROP TRIGGER IF EXISTS trg_set_experiment_id_on_soaking ON public.soaking;
CREATE TRIGGER trg_set_experiment_id_on_soaking
BEFORE INSERT OR UPDATE OF experiment_number, experiment_phase_id ON public.soaking
FOR EACH ROW
EXECUTE FUNCTION public.set_experiment_id_on_soaking();
DROP TRIGGER IF EXISTS trg_set_experiment_id_on_airdrying ON public.airdrying;
CREATE TRIGGER trg_set_experiment_id_on_airdrying
BEFORE INSERT OR UPDATE OF experiment_number, experiment_phase_id ON public.airdrying
FOR EACH ROW
EXECUTE FUNCTION public.set_experiment_id_on_airdrying();
DROP TRIGGER IF EXISTS trg_set_experiment_id_on_cracking ON public.cracking;
CREATE TRIGGER trg_set_experiment_id_on_cracking
BEFORE INSERT OR UPDATE OF experiment_number, experiment_phase_id ON public.cracking
FOR EACH ROW
EXECUTE FUNCTION public.set_experiment_id_on_cracking();
DROP TRIGGER IF EXISTS trg_set_experiment_id_on_shelling ON public.shelling;
CREATE TRIGGER trg_set_experiment_id_on_shelling
BEFORE INSERT OR UPDATE OF experiment_number, experiment_phase_id ON public.shelling
FOR EACH ROW
EXECUTE FUNCTION public.set_experiment_id_on_shelling();
-- 5) Make experiment_id NOT NULL after backfilling and triggers are in place
-- Only do this if there are no NULL values
DO $$
BEGIN
-- Check if all records have experiment_id populated before making it NOT NULL
IF NOT EXISTS (SELECT 1 FROM public.soaking WHERE experiment_id IS NULL) THEN
ALTER TABLE public.soaking ALTER COLUMN experiment_id SET NOT NULL;
END IF;
IF NOT EXISTS (SELECT 1 FROM public.airdrying WHERE experiment_id IS NULL) THEN
ALTER TABLE public.airdrying ALTER COLUMN experiment_id SET NOT NULL;
END IF;
IF NOT EXISTS (SELECT 1 FROM public.cracking WHERE experiment_id IS NULL) THEN
ALTER TABLE public.cracking ALTER COLUMN experiment_id SET NOT NULL;
END IF;
IF NOT EXISTS (SELECT 1 FROM public.shelling WHERE experiment_id IS NULL) THEN
ALTER TABLE public.shelling ALTER COLUMN experiment_id SET NOT NULL;
END IF;
END $$;
-- 6) Create indexes for experiment_id
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);
-- 7) Update unique constraints to use experiment_id instead of composite key
-- Drop old unique constraints
ALTER TABLE public.soaking DROP CONSTRAINT IF EXISTS unique_soaking_per_experiment;
ALTER TABLE public.airdrying DROP CONSTRAINT IF EXISTS unique_airdrying_per_experiment;
ALTER TABLE public.cracking DROP CONSTRAINT IF EXISTS unique_cracking_per_experiment;
ALTER TABLE public.shelling DROP CONSTRAINT IF EXISTS unique_shelling_per_experiment;
-- Add new unique constraints using experiment_id
ALTER TABLE public.soaking ADD CONSTRAINT unique_soaking_per_experiment UNIQUE (experiment_id);
ALTER TABLE public.airdrying ADD CONSTRAINT unique_airdrying_per_experiment UNIQUE (experiment_id);
ALTER TABLE public.cracking ADD CONSTRAINT unique_cracking_per_experiment UNIQUE (experiment_id);
ALTER TABLE public.shelling ADD CONSTRAINT unique_shelling_per_experiment UNIQUE (experiment_id);
COMMIT;

View File

@@ -258,7 +258,8 @@ SELECT
FROM public.user_profiles up
CROSS JOIN public.roles r
WHERE up.email = 'Brendan.Surio@uga.edu'
AND r.name = 'data recorder'
AND r.name IN ('conductor', 'data recorder')
;
-- Create William Mcconnell (Data Recorder)
@@ -306,7 +307,8 @@ SELECT
FROM public.user_profiles up
CROSS JOIN public.roles r
WHERE up.email = 'William.McConnell@uga.edu'
AND r.name = 'data recorder'
AND r.name IN ('conductor', 'data recorder')
;
-- Create Camille Deguzman (Data Recorder)
@@ -354,7 +356,8 @@ SELECT
FROM public.user_profiles up
CROSS JOIN public.roles r
WHERE up.email = 'cpd08598@uga.edu'
AND r.name = 'data recorder'
AND r.name IN ('conductor', 'data recorder')
;
-- Create Justin Hetzler (Data Recorder)
@@ -402,7 +405,8 @@ SELECT
FROM public.user_profiles up
CROSS JOIN public.roles r
WHERE up.email = 'Justin.Hetzler@uga.edu'
AND r.name = 'data recorder'
AND r.name IN ('conductor', 'data recorder')
;
-- Create Joshua Wilson (Data Recorder)
@@ -450,7 +454,8 @@ SELECT
FROM public.user_profiles up
CROSS JOIN public.roles r
WHERE up.email = 'jdw58940@uga.edu'
AND r.name = 'data recorder'
AND r.name IN ('conductor', 'data recorder')
;
-- Create Sydney Orlofsky (Data Recorder)
@@ -498,7 +503,8 @@ SELECT
FROM public.user_profiles up
CROSS JOIN public.roles r
WHERE up.email = 'Sydney.Orlofsky@uga.edu'
AND r.name = 'data recorder'
AND r.name IN ('conductor', 'data recorder')
;
-- =============================================

View File

@@ -1,13 +1,13 @@
-- Phase 2 JC Experiments Seed Data
-- This file contains all Phase 2 JC experiments from phase_2_experimental_run_sheet.csv
-- Phase 2 JC Experiments Seed Data (Corrected)
-- This file contains all Phase 2 JC experiments from phase_2_JC_experimental_run_sheet.csv
-- Each experiment has 3 repetitions, and each row represents one repetition
-- Updated to use 1-based numbering per phase and composite primary key
-- Updated to match the actual CSV data with correct experiment numbers and parameters
-- =============================================
-- INSERT PHASE 2 JC EXPERIMENTS
-- =============================================
-- First, insert unique experiments (based on experiment_number)
-- First, insert unique experiments (based on experiment_number from CSV: 0-19)
INSERT INTO public.experiments (
experiment_number,
reps_required,
@@ -16,8 +16,11 @@ INSERT INTO public.experiments (
phase_id,
created_by
) VALUES
-- Phase 2 JC Experiments 1-20 (1-based numbering)
(1, 3, 'valid', false,
-- Phase 2 JC Experiments 0-19 (matching CSV data)
(0, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(1, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(2, 3, 'valid', false,
@@ -72,9 +75,6 @@ INSERT INTO public.experiments (
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(19, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(20, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com'))
ON CONFLICT (experiment_number, phase_id) DO NOTHING;
@@ -83,67 +83,65 @@ ON CONFLICT (experiment_number, phase_id) DO NOTHING;
-- CREATE SOAKING PHASE RECORDS FOR PHASE 2 JC EXPERIMENTS
-- =============================================
-- Create soaking records for Phase 2 JC experiments (1-20)
-- Create soaking records for Phase 2 JC experiments (0-19) with data from CSV
INSERT INTO public.soaking (
experiment_id,
experiment_phase_id,
scheduled_start_time,
soaking_duration_hours,
soaking_duration_minutes,
scheduled_end_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
NOW() + (e.experiment_number) * INTERVAL '1 day',
e.id,
NOW() + (e.experiment_number + 1) * INTERVAL '1 day',
CASE e.experiment_number
WHEN 1 THEN 34 -- hours
WHEN 2 THEN 24
WHEN 3 THEN 38
WHEN 4 THEN 11
WHEN 5 THEN 13
WHEN 6 THEN 30
WHEN 7 THEN 10
WHEN 8 THEN 15
WHEN 9 THEN 27
WHEN 10 THEN 32
WHEN 11 THEN 26
WHEN 12 THEN 24
WHEN 13 THEN 28
WHEN 14 THEN 21
WHEN 15 THEN 22
WHEN 16 THEN 16
WHEN 17 THEN 20
WHEN 18 THEN 34
WHEN 19 THEN 18
WHEN 20 THEN 11
WHEN 0 THEN 34 * 60 -- 34 hours = 2040 minutes
WHEN 1 THEN 24 * 60 -- 24 hours = 1440 minutes
WHEN 2 THEN 38 * 60 -- 38 hours = 2280 minutes
WHEN 3 THEN 11 * 60 -- 11 hours = 660 minutes
WHEN 4 THEN 13 * 60 -- 13 hours = 780 minutes
WHEN 5 THEN 30 * 60 -- 30 hours = 1800 minutes
WHEN 6 THEN 10 * 60 -- 10 hours = 600 minutes
WHEN 7 THEN 15 * 60 -- 15 hours = 900 minutes
WHEN 8 THEN 27 * 60 -- 27 hours = 1620 minutes
WHEN 9 THEN 32 * 60 -- 32 hours = 1920 minutes
WHEN 10 THEN 26 * 60 -- 26 hours = 1560 minutes
WHEN 11 THEN 24 * 60 -- 24 hours = 1440 minutes
WHEN 12 THEN 28 * 60 -- 28 hours = 1680 minutes
WHEN 13 THEN 21 * 60 -- 21 hours = 1260 minutes
WHEN 14 THEN 22 * 60 -- 22 hours = 1320 minutes
WHEN 15 THEN 16 * 60 -- 16 hours = 960 minutes
WHEN 16 THEN 20 * 60 -- 20 hours = 1200 minutes
WHEN 17 THEN 34 * 60 -- 34 hours = 2040 minutes
WHEN 18 THEN 18 * 60 -- 18 hours = 1080 minutes
WHEN 19 THEN 11 * 60 -- 11 hours = 660 minutes
END,
NOW() + (e.experiment_number) * INTERVAL '1 day' +
NOW() + (e.experiment_number + 1) * INTERVAL '1 day' +
CASE e.experiment_number
WHEN 1 THEN 34 * INTERVAL '1 hour'
WHEN 2 THEN 24 * INTERVAL '1 hour'
WHEN 3 THEN 38 * INTERVAL '1 hour'
WHEN 4 THEN 11 * INTERVAL '1 hour'
WHEN 5 THEN 13 * INTERVAL '1 hour'
WHEN 6 THEN 30 * INTERVAL '1 hour'
WHEN 7 THEN 10 * INTERVAL '1 hour'
WHEN 8 THEN 15 * INTERVAL '1 hour'
WHEN 9 THEN 27 * INTERVAL '1 hour'
WHEN 10 THEN 32 * INTERVAL '1 hour'
WHEN 11 THEN 26 * INTERVAL '1 hour'
WHEN 12 THEN 24 * INTERVAL '1 hour'
WHEN 13 THEN 28 * INTERVAL '1 hour'
WHEN 14 THEN 21 * INTERVAL '1 hour'
WHEN 15 THEN 22 * INTERVAL '1 hour'
WHEN 16 THEN 16 * INTERVAL '1 hour'
WHEN 17 THEN 20 * INTERVAL '1 hour'
WHEN 18 THEN 34 * INTERVAL '1 hour'
WHEN 19 THEN 18 * INTERVAL '1 hour'
WHEN 20 THEN 11 * INTERVAL '1 hour'
WHEN 0 THEN 34 * 60 * INTERVAL '1 minute' -- 34 hours = 2040 minutes
WHEN 1 THEN 24 * 60 * INTERVAL '1 minute' -- 24 hours = 1440 minutes
WHEN 2 THEN 38 * 60 * INTERVAL '1 minute' -- 38 hours = 2280 minutes
WHEN 3 THEN 11 * 60 * INTERVAL '1 minute' -- 11 hours = 660 minutes
WHEN 4 THEN 13 * 60 * INTERVAL '1 minute' -- 13 hours = 780 minutes
WHEN 5 THEN 30 * 60 * INTERVAL '1 minute' -- 30 hours = 1800 minutes
WHEN 6 THEN 10 * 60 * INTERVAL '1 minute' -- 10 hours = 600 minutes
WHEN 7 THEN 15 * 60 * INTERVAL '1 minute' -- 15 hours = 900 minutes
WHEN 8 THEN 27 * 60 * INTERVAL '1 minute' -- 27 hours = 1620 minutes
WHEN 9 THEN 32 * 60 * INTERVAL '1 minute' -- 32 hours = 1920 minutes
WHEN 10 THEN 26 * 60 * INTERVAL '1 minute' -- 26 hours = 1560 minutes
WHEN 11 THEN 24 * 60 * INTERVAL '1 minute' -- 24 hours = 1440 minutes
WHEN 12 THEN 28 * 60 * INTERVAL '1 minute' -- 28 hours = 1680 minutes
WHEN 13 THEN 21 * 60 * INTERVAL '1 minute' -- 21 hours = 1260 minutes
WHEN 14 THEN 22 * 60 * INTERVAL '1 minute' -- 22 hours = 1320 minutes
WHEN 15 THEN 16 * 60 * INTERVAL '1 minute' -- 16 hours = 960 minutes
WHEN 16 THEN 20 * 60 * INTERVAL '1 minute' -- 20 hours = 1200 minutes
WHEN 17 THEN 34 * 60 * INTERVAL '1 minute' -- 34 hours = 2040 minutes
WHEN 18 THEN 18 * 60 * INTERVAL '1 minute' -- 18 hours = 1080 minutes
WHEN 19 THEN 11 * 60 * INTERVAL '1 minute' -- 11 hours = 660 minutes
END,
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 20
WHERE e.experiment_number BETWEEN 0 AND 19
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;
@@ -151,31 +149,30 @@ ON CONFLICT DO NOTHING;
-- CREATE AIRDRYING PHASE RECORDS FOR PHASE 2 JC EXPERIMENTS
-- =============================================
-- Create airdrying records for Phase 2 JC experiments (1-20)
-- Create airdrying records for Phase 2 JC experiments (0-19) with data from CSV
INSERT INTO public.airdrying (
experiment_id,
experiment_phase_id,
scheduled_start_time,
duration_minutes,
scheduled_end_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days', -- Start 2 days after soaking
e.id,
NOW() + (e.experiment_number + 1) * INTERVAL '1 day' + INTERVAL '2 days', -- Start 2 days after soaking
CASE e.experiment_number
WHEN 1 THEN 19 -- 19 minutes
WHEN 2 THEN 27 -- 27 minutes
WHEN 3 THEN 10 -- 10 minutes
WHEN 4 THEN 36 -- 36 minutes
WHEN 5 THEN 41 -- 41 minutes
WHEN 6 THEN 33 -- 33 minutes
WHEN 7 THEN 22 -- 22 minutes
WHEN 8 THEN 30 -- 30 minutes
WHEN 9 THEN 12 -- 12 minutes
WHEN 10 THEN 26 -- 26 minutes
WHEN 11 THEN 60 -- 60 minutes
WHEN 0 THEN 19 -- 19 minutes
WHEN 1 THEN 27 -- 27 minutes
WHEN 2 THEN 10 -- 10 minutes
WHEN 3 THEN 36 -- 36 minutes
WHEN 4 THEN 41 -- 41 minutes
WHEN 5 THEN 33 -- 33 minutes
WHEN 6 THEN 22 -- 22 minutes
WHEN 7 THEN 30 -- 30 minutes
WHEN 8 THEN 12 -- 12 minutes
WHEN 9 THEN 26 -- 26 minutes
WHEN 10 THEN 60 -- 60 minutes
WHEN 11 THEN 59 -- 59 minutes
WHEN 12 THEN 59 -- 59 minutes
WHEN 13 THEN 59 -- 59 minutes
WHEN 14 THEN 59 -- 59 minutes
@@ -184,21 +181,21 @@ SELECT
WHEN 17 THEN 60 -- 60 minutes
WHEN 18 THEN 49 -- 49 minutes
WHEN 19 THEN 25 -- 25 minutes
WHEN 20 THEN 25 -- 25 minutes
END,
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days' +
NOW() + (e.experiment_number + 1) * INTERVAL '1 day' + INTERVAL '2 days' +
CASE e.experiment_number
WHEN 1 THEN 19 * INTERVAL '1 minute' -- 19 minutes
WHEN 2 THEN 27 * INTERVAL '1 minute' -- 27 minutes
WHEN 3 THEN 10 * INTERVAL '1 minute' -- 10 minutes
WHEN 4 THEN 36 * INTERVAL '1 minute' -- 36 minutes
WHEN 5 THEN 41 * INTERVAL '1 minute' -- 41 minutes
WHEN 6 THEN 33 * INTERVAL '1 minute' -- 33 minutes
WHEN 7 THEN 22 * INTERVAL '1 minute' -- 22 minutes
WHEN 8 THEN 30 * INTERVAL '1 minute' -- 30 minutes
WHEN 9 THEN 12 * INTERVAL '1 minute' -- 12 minutes
WHEN 10 THEN 26 * INTERVAL '1 minute' -- 26 minutes
WHEN 11 THEN 60 * INTERVAL '1 minute' -- 60 minutes
WHEN 0 THEN 19 * INTERVAL '1 minute' -- 19 minutes
WHEN 1 THEN 27 * INTERVAL '1 minute' -- 27 minutes
WHEN 2 THEN 10 * INTERVAL '1 minute' -- 10 minutes
WHEN 3 THEN 36 * INTERVAL '1 minute' -- 36 minutes
WHEN 4 THEN 41 * INTERVAL '1 minute' -- 41 minutes
WHEN 5 THEN 33 * INTERVAL '1 minute' -- 33 minutes
WHEN 6 THEN 22 * INTERVAL '1 minute' -- 22 minutes
WHEN 7 THEN 30 * INTERVAL '1 minute' -- 30 minutes
WHEN 8 THEN 12 * INTERVAL '1 minute' -- 12 minutes
WHEN 9 THEN 26 * INTERVAL '1 minute' -- 26 minutes
WHEN 10 THEN 60 * INTERVAL '1 minute' -- 60 minutes
WHEN 11 THEN 59 * INTERVAL '1 minute' -- 59 minutes
WHEN 12 THEN 59 * INTERVAL '1 minute' -- 59 minutes
WHEN 13 THEN 59 * INTERVAL '1 minute' -- 59 minutes
WHEN 14 THEN 59 * INTERVAL '1 minute' -- 59 minutes
@@ -207,11 +204,10 @@ SELECT
WHEN 17 THEN 60 * INTERVAL '1 minute' -- 60 minutes
WHEN 18 THEN 49 * INTERVAL '1 minute' -- 49 minutes
WHEN 19 THEN 25 * INTERVAL '1 minute' -- 25 minutes
WHEN 20 THEN 25 * INTERVAL '1 minute' -- 25 minutes
END,
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 20
WHERE e.experiment_number BETWEEN 0 AND 19
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;
@@ -219,22 +215,20 @@ ON CONFLICT DO NOTHING;
-- CREATE CRACKING PHASE RECORDS FOR PHASE 2 JC EXPERIMENTS
-- =============================================
-- Create cracking records for Phase 2 JC experiments (1-20)
-- Create cracking records for Phase 2 JC experiments (0-19)
INSERT INTO public.cracking (
experiment_id,
experiment_phase_id,
machine_type_id,
scheduled_start_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
e.id,
(SELECT id FROM public.machine_types WHERE name = 'JC Cracker'),
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '3 days', -- Start 3 days after soaking
NOW() + (e.experiment_number + 1) * INTERVAL '1 day' + INTERVAL '3 days', -- Start 3 days after soaking
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 20
WHERE e.experiment_number BETWEEN 0 AND 19
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;
@@ -242,7 +236,7 @@ ON CONFLICT DO NOTHING;
-- CREATE JC CRACKER PARAMETERS FOR PHASE 2 JC EXPERIMENTS
-- =============================================
-- Create JC cracker parameters for Phase 2 JC experiments (1-20)
-- Create JC cracker parameters for Phase 2 JC experiments (0-19) with data from CSV
INSERT INTO public.jc_cracker_parameters (
cracking_id,
plate_contact_frequency_hz,
@@ -253,96 +247,96 @@ INSERT INTO public.jc_cracker_parameters (
SELECT
c.id,
CASE e.experiment_number
WHEN 1 THEN 53.0
WHEN 2 THEN 34.0
WHEN 3 THEN 60.0
WHEN 4 THEN 42.0
WHEN 5 THEN 41.0
WHEN 0 THEN 53.0
WHEN 1 THEN 34.0
WHEN 2 THEN 60.0
WHEN 3 THEN 42.0
WHEN 4 THEN 41.0
WHEN 5 THEN 30.0
WHEN 6 THEN 37.0
WHEN 7 THEN 35.0
WHEN 8 THEN 55.0
WHEN 9 THEN 47.0
WHEN 10 THEN 44.0
WHEN 11 THEN 42.0
WHEN 12 THEN 37.0
WHEN 13 THEN 41.0
WHEN 14 THEN 45.0
WHEN 15 THEN 30.0
WHEN 16 THEN 41.0
WHEN 17 THEN 34.0
WHEN 18 THEN 38.0
WHEN 19 THEN 56.0
END,
CASE e.experiment_number
WHEN 0 THEN 28.0
WHEN 1 THEN 29.0
WHEN 2 THEN 28.0
WHEN 3 THEN 13.0
WHEN 4 THEN 38.0
WHEN 5 THEN 36.0
WHEN 6 THEN 30.0
WHEN 7 THEN 37.0
WHEN 8 THEN 35.0
WHEN 9 THEN 55.0
WHEN 10 THEN 47.0
WHEN 11 THEN 44.0
WHEN 12 THEN 42.0
WHEN 13 THEN 37.0
WHEN 14 THEN 41.0
WHEN 15 THEN 45.0
WHEN 16 THEN 30.0
WHEN 17 THEN 41.0
WHEN 18 THEN 34.0
WHEN 19 THEN 38.0
WHEN 20 THEN 56.0
WHEN 7 THEN 32.0
WHEN 8 THEN 24.0
WHEN 9 THEN 26.0
WHEN 10 THEN 12.0
WHEN 11 THEN 25.0
WHEN 12 THEN 23.0
WHEN 13 THEN 21.0
WHEN 14 THEN 17.0
WHEN 15 THEN 24.0
WHEN 16 THEN 14.0
WHEN 17 THEN 29.0
WHEN 18 THEN 35.0
WHEN 19 THEN 34.0
END,
CASE e.experiment_number
WHEN 1 THEN 28.0
WHEN 2 THEN 29.0
WHEN 3 THEN 28.0
WHEN 4 THEN 13.0
WHEN 5 THEN 38.0
WHEN 6 THEN 36.0
WHEN 7 THEN 30.0
WHEN 8 THEN 32.0
WHEN 9 THEN 24.0
WHEN 10 THEN 26.0
WHEN 11 THEN 12.0
WHEN 12 THEN 25.0
WHEN 13 THEN 23.0
WHEN 14 THEN 21.0
WHEN 15 THEN 17.0
WHEN 16 THEN 24.0
WHEN 17 THEN 14.0
WHEN 18 THEN 29.0
WHEN 19 THEN 35.0
WHEN 20 THEN 34.0
END,
CASE e.experiment_number
WHEN 1 THEN 0.05
WHEN 2 THEN 0.03
WHEN 3 THEN 0.06
WHEN 4 THEN 0.07
WHEN 0 THEN 0.05
WHEN 1 THEN 0.03
WHEN 2 THEN 0.06
WHEN 3 THEN 0.07
WHEN 4 THEN 0.05
WHEN 5 THEN 0.05
WHEN 6 THEN 0.05
WHEN 7 THEN 0.06
WHEN 8 THEN 0.05
WHEN 9 THEN 0.04
WHEN 10 THEN 0.07
WHEN 11 THEN 0.08
WHEN 12 THEN 0.07
WHEN 6 THEN 0.06
WHEN 7 THEN 0.05
WHEN 8 THEN 0.04
WHEN 9 THEN 0.07
WHEN 10 THEN 0.08
WHEN 11 THEN 0.07
WHEN 12 THEN 0.06
WHEN 13 THEN 0.06
WHEN 14 THEN 0.06
WHEN 14 THEN 0.07
WHEN 15 THEN 0.07
WHEN 16 THEN 0.07
WHEN 17 THEN 0.07
WHEN 18 THEN 0.07
WHEN 19 THEN 0.07
WHEN 20 THEN 0.06
WHEN 19 THEN 0.06
END,
CASE e.experiment_number
WHEN 1 THEN -0.09
WHEN 2 THEN 0.01
WHEN 3 THEN -0.10
WHEN 4 THEN -0.07
WHEN 5 THEN 0.03
WHEN 6 THEN -0.04
WHEN 7 THEN 0.02
WHEN 8 THEN -0.07
WHEN 9 THEN 0.04
WHEN 10 THEN 0.03
WHEN 11 THEN -0.10
WHEN 12 THEN -0.05
WHEN 13 THEN -0.08
WHEN 14 THEN -0.09
WHEN 15 THEN -0.08
WHEN 16 THEN 0.02
WHEN 17 THEN 0.04
WHEN 18 THEN -0.09
WHEN 19 THEN -0.08
WHEN 20 THEN -0.09
WHEN 0 THEN -0.09
WHEN 1 THEN 0.01
WHEN 2 THEN -0.10
WHEN 3 THEN -0.07
WHEN 4 THEN 0.03
WHEN 5 THEN -0.04
WHEN 6 THEN 0.02
WHEN 7 THEN -0.07
WHEN 8 THEN 0.04
WHEN 9 THEN 0.03
WHEN 10 THEN -0.10
WHEN 11 THEN -0.05
WHEN 12 THEN -0.08
WHEN 13 THEN -0.09
WHEN 14 THEN -0.08
WHEN 15 THEN 0.02
WHEN 16 THEN 0.04
WHEN 17 THEN -0.09
WHEN 18 THEN -0.08
WHEN 19 THEN -0.09
END
FROM public.experiments e
JOIN public.cracking c ON c.experiment_id = e.experiment_number AND c.experiment_phase_id = e.phase_id
WHERE e.experiment_number BETWEEN 1 AND 20
JOIN public.cracking c ON c.experiment_id = e.id
WHERE e.experiment_number BETWEEN 0 AND 19
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;
@@ -354,19 +348,17 @@ ON CONFLICT DO NOTHING;
-- Each experiment needs 3 repetitions
INSERT INTO public.experiment_repetitions (
experiment_id,
experiment_phase_id,
repetition_number,
status,
completion_status,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
e.id,
rep_num,
'pending',
false,
e.created_by
FROM public.experiments e
CROSS JOIN generate_series(1, 3) AS rep_num
WHERE e.experiment_number BETWEEN 1 AND 20
WHERE e.experiment_number BETWEEN 0 AND 19
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;

View File

@@ -0,0 +1,372 @@
-- Phase 2 JC Experiments Seed Data
-- This file contains all Phase 2 JC experiments from phase_2_experimental_run_sheet.csv
-- Each experiment has 3 repetitions, and each row represents one repetition
-- Updated to use 1-based numbering per phase and composite primary key
-- =============================================
-- INSERT PHASE 2 JC EXPERIMENTS
-- =============================================
-- First, insert unique experiments (based on experiment_number)
INSERT INTO public.experiments (
experiment_number,
reps_required,
results_status,
completion_status,
phase_id,
created_by
) VALUES
-- Phase 2 JC Experiments 1-20 (1-based numbering)
(1, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(2, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(3, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(4, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(5, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(6, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(7, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(8, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(9, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(10, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(11, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(12, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(13, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(14, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(15, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(16, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(17, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(18, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(19, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(20, 3, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com'))
ON CONFLICT (experiment_number, phase_id) DO NOTHING;
-- =============================================
-- CREATE SOAKING PHASE RECORDS FOR PHASE 2 JC EXPERIMENTS
-- =============================================
-- Create soaking records for Phase 2 JC experiments (1-20)
INSERT INTO public.soaking (
experiment_number,
experiment_phase_id,
scheduled_start_time,
soaking_duration_hours,
scheduled_end_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
NOW() + (e.experiment_number) * INTERVAL '1 day',
CASE e.experiment_number
WHEN 1 THEN 34 -- hours
WHEN 2 THEN 24
WHEN 3 THEN 38
WHEN 4 THEN 11
WHEN 5 THEN 13
WHEN 6 THEN 30
WHEN 7 THEN 10
WHEN 8 THEN 15
WHEN 9 THEN 27
WHEN 10 THEN 32
WHEN 11 THEN 26
WHEN 12 THEN 24
WHEN 13 THEN 28
WHEN 14 THEN 21
WHEN 15 THEN 22
WHEN 16 THEN 16
WHEN 17 THEN 20
WHEN 18 THEN 34
WHEN 19 THEN 18
WHEN 20 THEN 11
END,
NOW() + (e.experiment_number) * INTERVAL '1 day' +
CASE e.experiment_number
WHEN 1 THEN 34 * INTERVAL '1 hour'
WHEN 2 THEN 24 * INTERVAL '1 hour'
WHEN 3 THEN 38 * INTERVAL '1 hour'
WHEN 4 THEN 11 * INTERVAL '1 hour'
WHEN 5 THEN 13 * INTERVAL '1 hour'
WHEN 6 THEN 30 * INTERVAL '1 hour'
WHEN 7 THEN 10 * INTERVAL '1 hour'
WHEN 8 THEN 15 * INTERVAL '1 hour'
WHEN 9 THEN 27 * INTERVAL '1 hour'
WHEN 10 THEN 32 * INTERVAL '1 hour'
WHEN 11 THEN 26 * INTERVAL '1 hour'
WHEN 12 THEN 24 * INTERVAL '1 hour'
WHEN 13 THEN 28 * INTERVAL '1 hour'
WHEN 14 THEN 21 * INTERVAL '1 hour'
WHEN 15 THEN 22 * INTERVAL '1 hour'
WHEN 16 THEN 16 * INTERVAL '1 hour'
WHEN 17 THEN 20 * INTERVAL '1 hour'
WHEN 18 THEN 34 * INTERVAL '1 hour'
WHEN 19 THEN 18 * INTERVAL '1 hour'
WHEN 20 THEN 11 * INTERVAL '1 hour'
END,
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 20
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;
-- =============================================
-- CREATE AIRDRYING PHASE RECORDS FOR PHASE 2 JC EXPERIMENTS
-- =============================================
-- Create airdrying records for Phase 2 JC experiments (1-20)
INSERT INTO public.airdrying (
experiment_number,
experiment_phase_id,
scheduled_start_time,
duration_minutes,
scheduled_end_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days', -- Start 2 days after soaking
CASE e.experiment_number
WHEN 1 THEN 19 -- 19 minutes
WHEN 2 THEN 27 -- 27 minutes
WHEN 3 THEN 10 -- 10 minutes
WHEN 4 THEN 36 -- 36 minutes
WHEN 5 THEN 41 -- 41 minutes
WHEN 6 THEN 33 -- 33 minutes
WHEN 7 THEN 22 -- 22 minutes
WHEN 8 THEN 30 -- 30 minutes
WHEN 9 THEN 12 -- 12 minutes
WHEN 10 THEN 26 -- 26 minutes
WHEN 11 THEN 60 -- 60 minutes
WHEN 12 THEN 59 -- 59 minutes
WHEN 13 THEN 59 -- 59 minutes
WHEN 14 THEN 59 -- 59 minutes
WHEN 15 THEN 60 -- 60 minutes
WHEN 16 THEN 59 -- 59 minutes
WHEN 17 THEN 60 -- 60 minutes
WHEN 18 THEN 49 -- 49 minutes
WHEN 19 THEN 25 -- 25 minutes
WHEN 20 THEN 25 -- 25 minutes
END,
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days' +
CASE e.experiment_number
WHEN 1 THEN 19 * INTERVAL '1 minute' -- 19 minutes
WHEN 2 THEN 27 * INTERVAL '1 minute' -- 27 minutes
WHEN 3 THEN 10 * INTERVAL '1 minute' -- 10 minutes
WHEN 4 THEN 36 * INTERVAL '1 minute' -- 36 minutes
WHEN 5 THEN 41 * INTERVAL '1 minute' -- 41 minutes
WHEN 6 THEN 33 * INTERVAL '1 minute' -- 33 minutes
WHEN 7 THEN 22 * INTERVAL '1 minute' -- 22 minutes
WHEN 8 THEN 30 * INTERVAL '1 minute' -- 30 minutes
WHEN 9 THEN 12 * INTERVAL '1 minute' -- 12 minutes
WHEN 10 THEN 26 * INTERVAL '1 minute' -- 26 minutes
WHEN 11 THEN 60 * INTERVAL '1 minute' -- 60 minutes
WHEN 12 THEN 59 * INTERVAL '1 minute' -- 59 minutes
WHEN 13 THEN 59 * INTERVAL '1 minute' -- 59 minutes
WHEN 14 THEN 59 * INTERVAL '1 minute' -- 59 minutes
WHEN 15 THEN 60 * INTERVAL '1 minute' -- 60 minutes
WHEN 16 THEN 59 * INTERVAL '1 minute' -- 59 minutes
WHEN 17 THEN 60 * INTERVAL '1 minute' -- 60 minutes
WHEN 18 THEN 49 * INTERVAL '1 minute' -- 49 minutes
WHEN 19 THEN 25 * INTERVAL '1 minute' -- 25 minutes
WHEN 20 THEN 25 * INTERVAL '1 minute' -- 25 minutes
END,
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 20
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;
-- =============================================
-- CREATE CRACKING PHASE RECORDS FOR PHASE 2 JC EXPERIMENTS
-- =============================================
-- Create cracking records for Phase 2 JC experiments (1-20)
INSERT INTO public.cracking (
experiment_number,
experiment_phase_id,
machine_type_id,
scheduled_start_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
(SELECT id FROM public.machine_types WHERE name = 'JC Cracker'),
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '3 days', -- Start 3 days after soaking
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 20
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;
-- =============================================
-- CREATE JC CRACKER PARAMETERS FOR PHASE 2 JC EXPERIMENTS
-- =============================================
-- Create JC cracker parameters for Phase 2 JC experiments (1-20)
INSERT INTO public.jc_cracker_parameters (
cracking_id,
plate_contact_frequency_hz,
throughput_rate_pecans_sec,
crush_amount_in,
entry_exit_height_diff_in
)
SELECT
c.id,
CASE e.experiment_number
WHEN 1 THEN 53.0
WHEN 2 THEN 34.0
WHEN 3 THEN 60.0
WHEN 4 THEN 42.0
WHEN 5 THEN 41.0
WHEN 6 THEN 30.0
WHEN 7 THEN 37.0
WHEN 8 THEN 35.0
WHEN 9 THEN 55.0
WHEN 10 THEN 47.0
WHEN 11 THEN 44.0
WHEN 12 THEN 42.0
WHEN 13 THEN 37.0
WHEN 14 THEN 41.0
WHEN 15 THEN 45.0
WHEN 16 THEN 30.0
WHEN 17 THEN 41.0
WHEN 18 THEN 34.0
WHEN 19 THEN 38.0
WHEN 20 THEN 56.0
END,
CASE e.experiment_number
WHEN 1 THEN 28.0
WHEN 2 THEN 29.0
WHEN 3 THEN 28.0
WHEN 4 THEN 13.0
WHEN 5 THEN 38.0
WHEN 6 THEN 36.0
WHEN 7 THEN 30.0
WHEN 8 THEN 32.0
WHEN 9 THEN 24.0
WHEN 10 THEN 26.0
WHEN 11 THEN 12.0
WHEN 12 THEN 25.0
WHEN 13 THEN 23.0
WHEN 14 THEN 21.0
WHEN 15 THEN 17.0
WHEN 16 THEN 24.0
WHEN 17 THEN 14.0
WHEN 18 THEN 29.0
WHEN 19 THEN 35.0
WHEN 20 THEN 34.0
END,
CASE e.experiment_number
WHEN 1 THEN 0.05
WHEN 2 THEN 0.03
WHEN 3 THEN 0.06
WHEN 4 THEN 0.07
WHEN 5 THEN 0.05
WHEN 6 THEN 0.05
WHEN 7 THEN 0.06
WHEN 8 THEN 0.05
WHEN 9 THEN 0.04
WHEN 10 THEN 0.07
WHEN 11 THEN 0.08
WHEN 12 THEN 0.07
WHEN 13 THEN 0.06
WHEN 14 THEN 0.06
WHEN 15 THEN 0.07
WHEN 16 THEN 0.07
WHEN 17 THEN 0.07
WHEN 18 THEN 0.07
WHEN 19 THEN 0.07
WHEN 20 THEN 0.06
END,
CASE e.experiment_number
WHEN 1 THEN -0.09
WHEN 2 THEN 0.01
WHEN 3 THEN -0.10
WHEN 4 THEN -0.07
WHEN 5 THEN 0.03
WHEN 6 THEN -0.04
WHEN 7 THEN 0.02
WHEN 8 THEN -0.07
WHEN 9 THEN 0.04
WHEN 10 THEN 0.03
WHEN 11 THEN -0.10
WHEN 12 THEN -0.05
WHEN 13 THEN -0.08
WHEN 14 THEN -0.09
WHEN 15 THEN -0.08
WHEN 16 THEN 0.02
WHEN 17 THEN 0.04
WHEN 18 THEN -0.09
WHEN 19 THEN -0.08
WHEN 20 THEN -0.09
END
FROM public.experiments e
JOIN public.cracking c ON c.experiment_number = e.experiment_number AND c.experiment_phase_id = e.phase_id
WHERE e.experiment_number BETWEEN 1 AND 20
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;
-- =============================================
-- CREATE EXPERIMENT REPETITIONS FOR PHASE 2 JC EXPERIMENTS
-- =============================================
-- Create experiment repetitions for Phase 2 JC experiments
-- Each experiment needs 3 repetitions
INSERT INTO public.experiment_repetitions (
experiment_number,
experiment_phase_id,
repetition_number,
status,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
rep_num,
'pending',
e.created_by
FROM public.experiments e
CROSS JOIN generate_series(1, 3) AS rep_num
WHERE e.experiment_number BETWEEN 1 AND 20
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;

View File

@@ -370,3 +370,4 @@ CROSS JOIN generate_series(1, 3) AS rep_num
WHERE e.experiment_number BETWEEN 1 AND 20
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments')
ON CONFLICT DO NOTHING;

View File

@@ -1,13 +1,13 @@
-- Meyer Experiments Seed Data
-- This file contains all 40 Meyer experiments from meyer experiments.csv
-- Meyer Experiments Seed Data (Corrected)
-- This file contains all 40 Meyer experiments from post_workshop_meyer_experiments.csv
-- Each experiment has only 1 repetition required
-- Updated to use 1-based numbering per phase and composite primary key
-- Updated to match the actual CSV data with correct experiment numbers and parameters
-- =============================================
-- INSERT MEYER EXPERIMENTS (Post Workshop)
-- =============================================
-- Insert Meyer experiments (experiments 1-40)
-- Insert Meyer experiments (experiments 1-40) with data from CSV
INSERT INTO public.experiments (
experiment_number,
reps_required,
@@ -16,7 +16,7 @@ INSERT INTO public.experiments (
phase_id,
created_by
) VALUES
-- Meyer Experiments 1-40 (1-based numbering)
-- Meyer Experiments 1-40 (matching CSV data)
(1, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
@@ -143,103 +143,101 @@ ON CONFLICT (experiment_number, phase_id) DO NOTHING;
-- CREATE SOAKING PHASE RECORDS FOR MEYER EXPERIMENTS
-- =============================================
-- Create soaking records for Meyer experiments (1-40)
-- Create soaking records for Meyer experiments (1-40) with data from CSV
INSERT INTO public.soaking (
experiment_id,
experiment_phase_id,
scheduled_start_time,
soaking_duration_hours,
soaking_duration_minutes,
scheduled_end_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
NOW() + (e.experiment_number) * INTERVAL '1 day',
e.id,
NOW() + e.experiment_number * INTERVAL '1 day',
CASE e.experiment_number
WHEN 1 THEN 27 -- hours
WHEN 2 THEN 37
WHEN 3 THEN 36
WHEN 4 THEN 12
WHEN 5 THEN 34
WHEN 6 THEN 18
WHEN 7 THEN 14
WHEN 8 THEN 18
WHEN 9 THEN 11
WHEN 10 THEN 33
WHEN 11 THEN 23
WHEN 12 THEN 37
WHEN 13 THEN 15
WHEN 14 THEN 24
WHEN 15 THEN 36
WHEN 16 THEN 32
WHEN 17 THEN 28
WHEN 18 THEN 31
WHEN 19 THEN 20
WHEN 20 THEN 10
WHEN 21 THEN 16
WHEN 22 THEN 21
WHEN 23 THEN 42
WHEN 24 THEN 29
WHEN 25 THEN 54
WHEN 26 THEN 29
WHEN 27 THEN 30
WHEN 28 THEN 35
WHEN 29 THEN 27
WHEN 30 THEN 27
WHEN 31 THEN 17
WHEN 32 THEN 13
WHEN 33 THEN 19
WHEN 34 THEN 38
WHEN 35 THEN 26
WHEN 36 THEN 22
WHEN 37 THEN 12
WHEN 38 THEN 16
WHEN 39 THEN 22
WHEN 40 THEN 24
WHEN 1 THEN 27 * 60 -- 27 hours = 1620 minutes
WHEN 2 THEN 37 * 60 -- 37 hours = 2220 minutes
WHEN 3 THEN 36 * 60 -- 36 hours = 2160 minutes
WHEN 4 THEN 12 * 60 -- 12 hours = 720 minutes
WHEN 5 THEN 34 * 60 -- 34 hours = 2040 minutes
WHEN 6 THEN 18 * 60 -- 18 hours = 1080 minutes
WHEN 7 THEN 14 * 60 -- 14 hours = 840 minutes
WHEN 8 THEN 18 * 60 -- 18 hours = 1080 minutes
WHEN 9 THEN 11 * 60 -- 11 hours = 660 minutes
WHEN 10 THEN 33 * 60 -- 33 hours = 1980 minutes
WHEN 11 THEN 23 * 60 -- 23 hours = 1380 minutes
WHEN 12 THEN 37 * 60 -- 37 hours = 2220 minutes
WHEN 13 THEN 15 * 60 -- 15 hours = 900 minutes
WHEN 14 THEN 24 * 60 -- 24 hours = 1440 minutes
WHEN 15 THEN 36 * 60 -- 36 hours = 2160 minutes
WHEN 16 THEN 32 * 60 -- 32 hours = 1920 minutes
WHEN 17 THEN 28 * 60 -- 28 hours = 1680 minutes
WHEN 18 THEN 31 * 60 -- 31 hours = 1860 minutes
WHEN 19 THEN 20 * 60 -- 20 hours = 1200 minutes
WHEN 20 THEN 10 * 60 -- 10 hours = 600 minutes
WHEN 21 THEN 16 * 60 -- 16 hours = 960 minutes
WHEN 22 THEN 21 * 60 -- 21 hours = 1260 minutes
WHEN 23 THEN 42 * 60 -- 42 hours = 2520 minutes
WHEN 24 THEN 29 * 60 -- 29 hours = 1740 minutes
WHEN 25 THEN 54 * 60 -- 54 hours = 3240 minutes
WHEN 26 THEN 29 * 60 -- 29 hours = 1740 minutes
WHEN 27 THEN 30 * 60 -- 30 hours = 1800 minutes
WHEN 28 THEN 35 * 60 -- 35 hours = 2100 minutes
WHEN 29 THEN 27 * 60 -- 27 hours = 1620 minutes
WHEN 30 THEN 27 * 60 -- 27 hours = 1620 minutes
WHEN 31 THEN 17 * 60 -- 17 hours = 1020 minutes
WHEN 32 THEN 13 * 60 -- 13 hours = 780 minutes
WHEN 33 THEN 19 * 60 -- 19 hours = 1140 minutes
WHEN 34 THEN 38 * 60 -- 38 hours = 2280 minutes
WHEN 35 THEN 26 * 60 -- 26 hours = 1560 minutes
WHEN 36 THEN 22 * 60 -- 22 hours = 1320 minutes
WHEN 37 THEN 12 * 60 -- 12 hours = 720 minutes
WHEN 38 THEN 16 * 60 -- 16 hours = 960 minutes
WHEN 39 THEN 22 * 60 -- 22 hours = 1320 minutes
WHEN 40 THEN 24 * 60 -- 24 hours = 1440 minutes
END,
NOW() + (e.experiment_number) * INTERVAL '1 day' +
NOW() + e.experiment_number * INTERVAL '1 day' +
CASE e.experiment_number
WHEN 1 THEN 27 * INTERVAL '1 hour'
WHEN 2 THEN 37 * INTERVAL '1 hour'
WHEN 3 THEN 36 * INTERVAL '1 hour'
WHEN 4 THEN 12 * INTERVAL '1 hour'
WHEN 5 THEN 34 * INTERVAL '1 hour'
WHEN 6 THEN 18 * INTERVAL '1 hour'
WHEN 7 THEN 14 * INTERVAL '1 hour'
WHEN 8 THEN 18 * INTERVAL '1 hour'
WHEN 9 THEN 11 * INTERVAL '1 hour'
WHEN 10 THEN 33 * INTERVAL '1 hour'
WHEN 11 THEN 23 * INTERVAL '1 hour'
WHEN 12 THEN 37 * INTERVAL '1 hour'
WHEN 13 THEN 15 * INTERVAL '1 hour'
WHEN 14 THEN 24 * INTERVAL '1 hour'
WHEN 15 THEN 36 * INTERVAL '1 hour'
WHEN 16 THEN 32 * INTERVAL '1 hour'
WHEN 17 THEN 28 * INTERVAL '1 hour'
WHEN 18 THEN 31 * INTERVAL '1 hour'
WHEN 19 THEN 20 * INTERVAL '1 hour'
WHEN 20 THEN 10 * INTERVAL '1 hour'
WHEN 21 THEN 16 * INTERVAL '1 hour'
WHEN 22 THEN 21 * INTERVAL '1 hour'
WHEN 23 THEN 42 * INTERVAL '1 hour'
WHEN 24 THEN 29 * INTERVAL '1 hour'
WHEN 25 THEN 54 * INTERVAL '1 hour'
WHEN 26 THEN 29 * INTERVAL '1 hour'
WHEN 27 THEN 30 * INTERVAL '1 hour'
WHEN 28 THEN 35 * INTERVAL '1 hour'
WHEN 29 THEN 27 * INTERVAL '1 hour'
WHEN 30 THEN 27 * INTERVAL '1 hour'
WHEN 31 THEN 17 * INTERVAL '1 hour'
WHEN 32 THEN 13 * INTERVAL '1 hour'
WHEN 33 THEN 19 * INTERVAL '1 hour'
WHEN 34 THEN 38 * INTERVAL '1 hour'
WHEN 35 THEN 26 * INTERVAL '1 hour'
WHEN 36 THEN 22 * INTERVAL '1 hour'
WHEN 37 THEN 12 * INTERVAL '1 hour'
WHEN 38 THEN 16 * INTERVAL '1 hour'
WHEN 39 THEN 22 * INTERVAL '1 hour'
WHEN 40 THEN 24 * INTERVAL '1 hour'
WHEN 1 THEN 27 * 60 * INTERVAL '1 minute' -- 27 hours = 1620 minutes
WHEN 2 THEN 37 * 60 * INTERVAL '1 minute' -- 37 hours = 2220 minutes
WHEN 3 THEN 36 * 60 * INTERVAL '1 minute' -- 36 hours = 2160 minutes
WHEN 4 THEN 12 * 60 * INTERVAL '1 minute' -- 12 hours = 720 minutes
WHEN 5 THEN 34 * 60 * INTERVAL '1 minute' -- 34 hours = 2040 minutes
WHEN 6 THEN 18 * 60 * INTERVAL '1 minute' -- 18 hours = 1080 minutes
WHEN 7 THEN 14 * 60 * INTERVAL '1 minute' -- 14 hours = 840 minutes
WHEN 8 THEN 18 * 60 * INTERVAL '1 minute' -- 18 hours = 1080 minutes
WHEN 9 THEN 11 * 60 * INTERVAL '1 minute' -- 11 hours = 660 minutes
WHEN 10 THEN 33 * 60 * INTERVAL '1 minute' -- 33 hours = 1980 minutes
WHEN 11 THEN 23 * 60 * INTERVAL '1 minute' -- 23 hours = 1380 minutes
WHEN 12 THEN 37 * 60 * INTERVAL '1 minute' -- 37 hours = 2220 minutes
WHEN 13 THEN 15 * 60 * INTERVAL '1 minute' -- 15 hours = 900 minutes
WHEN 14 THEN 24 * 60 * INTERVAL '1 minute' -- 24 hours = 1440 minutes
WHEN 15 THEN 36 * 60 * INTERVAL '1 minute' -- 36 hours = 2160 minutes
WHEN 16 THEN 32 * 60 * INTERVAL '1 minute' -- 32 hours = 1920 minutes
WHEN 17 THEN 28 * 60 * INTERVAL '1 minute' -- 28 hours = 1680 minutes
WHEN 18 THEN 31 * 60 * INTERVAL '1 minute' -- 31 hours = 1860 minutes
WHEN 19 THEN 20 * 60 * INTERVAL '1 minute' -- 20 hours = 1200 minutes
WHEN 20 THEN 10 * 60 * INTERVAL '1 minute' -- 10 hours = 600 minutes
WHEN 21 THEN 16 * 60 * INTERVAL '1 minute' -- 16 hours = 960 minutes
WHEN 22 THEN 21 * 60 * INTERVAL '1 minute' -- 21 hours = 1260 minutes
WHEN 23 THEN 42 * 60 * INTERVAL '1 minute' -- 42 hours = 2520 minutes
WHEN 24 THEN 29 * 60 * INTERVAL '1 minute' -- 29 hours = 1740 minutes
WHEN 25 THEN 54 * 60 * INTERVAL '1 minute' -- 54 hours = 3240 minutes
WHEN 26 THEN 29 * 60 * INTERVAL '1 minute' -- 29 hours = 1740 minutes
WHEN 27 THEN 30 * 60 * INTERVAL '1 minute' -- 30 hours = 1800 minutes
WHEN 28 THEN 35 * 60 * INTERVAL '1 minute' -- 35 hours = 2100 minutes
WHEN 29 THEN 27 * 60 * INTERVAL '1 minute' -- 27 hours = 1620 minutes
WHEN 30 THEN 27 * 60 * INTERVAL '1 minute' -- 27 hours = 1620 minutes
WHEN 31 THEN 17 * 60 * INTERVAL '1 minute' -- 17 hours = 1020 minutes
WHEN 32 THEN 13 * 60 * INTERVAL '1 minute' -- 13 hours = 780 minutes
WHEN 33 THEN 19 * 60 * INTERVAL '1 minute' -- 19 hours = 1140 minutes
WHEN 34 THEN 38 * 60 * INTERVAL '1 minute' -- 38 hours = 2280 minutes
WHEN 35 THEN 26 * 60 * INTERVAL '1 minute' -- 26 hours = 1560 minutes
WHEN 36 THEN 22 * 60 * INTERVAL '1 minute' -- 22 hours = 1320 minutes
WHEN 37 THEN 12 * 60 * INTERVAL '1 minute' -- 12 hours = 720 minutes
WHEN 38 THEN 16 * 60 * INTERVAL '1 minute' -- 16 hours = 960 minutes
WHEN 39 THEN 22 * 60 * INTERVAL '1 minute' -- 22 hours = 1320 minutes
WHEN 40 THEN 24 * 60 * INTERVAL '1 minute' -- 24 hours = 1440 minutes
END,
e.created_by
FROM public.experiments e
@@ -251,19 +249,17 @@ ON CONFLICT DO NOTHING;
-- CREATE AIRDRYING PHASE RECORDS FOR MEYER EXPERIMENTS
-- =============================================
-- Create airdrying records for Meyer experiments (1-40)
-- Create airdrying records for Meyer experiments (1-40) with data from CSV
INSERT INTO public.airdrying (
experiment_id,
experiment_phase_id,
scheduled_start_time,
duration_minutes,
scheduled_end_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days', -- Start 2 days after soaking
e.id,
NOW() + e.experiment_number * INTERVAL '1 day' + INTERVAL '2 days', -- Start 2 days after soaking
CASE e.experiment_number
WHEN 1 THEN 28 -- 28 minutes
WHEN 2 THEN 17 -- 17 minutes
@@ -306,7 +302,7 @@ SELECT
WHEN 39 THEN 25 -- 25 minutes
WHEN 40 THEN 13 -- 13 minutes
END,
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days' +
NOW() + e.experiment_number * INTERVAL '1 day' + INTERVAL '2 days' +
CASE e.experiment_number
WHEN 1 THEN 28 * INTERVAL '1 minute' -- 28 minutes
WHEN 2 THEN 17 * INTERVAL '1 minute' -- 17 minutes
@@ -362,16 +358,14 @@ ON CONFLICT DO NOTHING;
-- Create cracking records for Meyer experiments (1-40)
INSERT INTO public.cracking (
experiment_id,
experiment_phase_id,
machine_type_id,
scheduled_start_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
e.id,
(SELECT id FROM public.machine_types WHERE name = 'Meyer Cracker'),
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '3 days', -- Start 3 days after soaking
NOW() + e.experiment_number * INTERVAL '1 day' + INTERVAL '3 days', -- Start 3 days after soaking
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 40
@@ -382,7 +376,7 @@ ON CONFLICT DO NOTHING;
-- CREATE MEYER CRACKER PARAMETERS FOR MEYER EXPERIMENTS
-- =============================================
-- Create Meyer cracker parameters for Meyer experiments (1-40)
-- Create Meyer cracker parameters for Meyer experiments (1-40) with data from CSV
INSERT INTO public.meyer_cracker_parameters (
cracking_id,
motor_speed_hz,
@@ -518,7 +512,7 @@ SELECT
WHEN 40 THEN 2000.0
END
FROM public.experiments e
JOIN public.cracking c ON c.experiment_id = e.experiment_number AND c.experiment_phase_id = e.phase_id
JOIN public.cracking c ON c.experiment_id = e.id
WHERE e.experiment_number BETWEEN 1 AND 40
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments')
ON CONFLICT DO NOTHING;
@@ -531,16 +525,14 @@ ON CONFLICT DO NOTHING;
-- Each experiment needs only 1 repetition
INSERT INTO public.experiment_repetitions (
experiment_id,
experiment_phase_id,
repetition_number,
status,
completion_status,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
e.id,
1,
'pending',
false,
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 40

View File

@@ -0,0 +1,548 @@
-- Meyer Experiments Seed Data
-- This file contains all 40 Meyer experiments from meyer experiments.csv
-- Each experiment has only 1 repetition required
-- Updated to use 1-based numbering per phase and composite primary key
-- =============================================
-- INSERT MEYER EXPERIMENTS (Post Workshop)
-- =============================================
-- Insert Meyer experiments (experiments 1-40)
INSERT INTO public.experiments (
experiment_number,
reps_required,
results_status,
completion_status,
phase_id,
created_by
) VALUES
-- Meyer Experiments 1-40 (1-based numbering)
(1, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(2, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(3, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(4, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(5, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(6, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(7, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(8, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(9, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(10, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(11, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(12, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(13, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(14, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(15, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(16, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(17, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(18, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(19, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(20, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(21, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(22, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(23, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(24, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(25, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(26, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(27, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(28, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(29, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(30, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(31, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(32, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(33, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(34, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(35, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(36, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(37, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(38, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(39, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(40, 1, 'valid', false,
(SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments'),
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com'))
ON CONFLICT (experiment_number, phase_id) DO NOTHING;
-- =============================================
-- CREATE SOAKING PHASE RECORDS FOR MEYER EXPERIMENTS
-- =============================================
-- Create soaking records for Meyer experiments (1-40)
INSERT INTO public.soaking (
experiment_number,
experiment_phase_id,
scheduled_start_time,
soaking_duration_hours,
scheduled_end_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
NOW() + (e.experiment_number) * INTERVAL '1 day',
CASE e.experiment_number
WHEN 1 THEN 27 -- hours
WHEN 2 THEN 37
WHEN 3 THEN 36
WHEN 4 THEN 12
WHEN 5 THEN 34
WHEN 6 THEN 18
WHEN 7 THEN 14
WHEN 8 THEN 18
WHEN 9 THEN 11
WHEN 10 THEN 33
WHEN 11 THEN 23
WHEN 12 THEN 37
WHEN 13 THEN 15
WHEN 14 THEN 24
WHEN 15 THEN 36
WHEN 16 THEN 32
WHEN 17 THEN 28
WHEN 18 THEN 31
WHEN 19 THEN 20
WHEN 20 THEN 10
WHEN 21 THEN 16
WHEN 22 THEN 21
WHEN 23 THEN 42
WHEN 24 THEN 29
WHEN 25 THEN 54
WHEN 26 THEN 29
WHEN 27 THEN 30
WHEN 28 THEN 35
WHEN 29 THEN 27
WHEN 30 THEN 27
WHEN 31 THEN 17
WHEN 32 THEN 13
WHEN 33 THEN 19
WHEN 34 THEN 38
WHEN 35 THEN 26
WHEN 36 THEN 22
WHEN 37 THEN 12
WHEN 38 THEN 16
WHEN 39 THEN 22
WHEN 40 THEN 24
END,
NOW() + (e.experiment_number) * INTERVAL '1 day' +
CASE e.experiment_number
WHEN 1 THEN 27 * INTERVAL '1 hour'
WHEN 2 THEN 37 * INTERVAL '1 hour'
WHEN 3 THEN 36 * INTERVAL '1 hour'
WHEN 4 THEN 12 * INTERVAL '1 hour'
WHEN 5 THEN 34 * INTERVAL '1 hour'
WHEN 6 THEN 18 * INTERVAL '1 hour'
WHEN 7 THEN 14 * INTERVAL '1 hour'
WHEN 8 THEN 18 * INTERVAL '1 hour'
WHEN 9 THEN 11 * INTERVAL '1 hour'
WHEN 10 THEN 33 * INTERVAL '1 hour'
WHEN 11 THEN 23 * INTERVAL '1 hour'
WHEN 12 THEN 37 * INTERVAL '1 hour'
WHEN 13 THEN 15 * INTERVAL '1 hour'
WHEN 14 THEN 24 * INTERVAL '1 hour'
WHEN 15 THEN 36 * INTERVAL '1 hour'
WHEN 16 THEN 32 * INTERVAL '1 hour'
WHEN 17 THEN 28 * INTERVAL '1 hour'
WHEN 18 THEN 31 * INTERVAL '1 hour'
WHEN 19 THEN 20 * INTERVAL '1 hour'
WHEN 20 THEN 10 * INTERVAL '1 hour'
WHEN 21 THEN 16 * INTERVAL '1 hour'
WHEN 22 THEN 21 * INTERVAL '1 hour'
WHEN 23 THEN 42 * INTERVAL '1 hour'
WHEN 24 THEN 29 * INTERVAL '1 hour'
WHEN 25 THEN 54 * INTERVAL '1 hour'
WHEN 26 THEN 29 * INTERVAL '1 hour'
WHEN 27 THEN 30 * INTERVAL '1 hour'
WHEN 28 THEN 35 * INTERVAL '1 hour'
WHEN 29 THEN 27 * INTERVAL '1 hour'
WHEN 30 THEN 27 * INTERVAL '1 hour'
WHEN 31 THEN 17 * INTERVAL '1 hour'
WHEN 32 THEN 13 * INTERVAL '1 hour'
WHEN 33 THEN 19 * INTERVAL '1 hour'
WHEN 34 THEN 38 * INTERVAL '1 hour'
WHEN 35 THEN 26 * INTERVAL '1 hour'
WHEN 36 THEN 22 * INTERVAL '1 hour'
WHEN 37 THEN 12 * INTERVAL '1 hour'
WHEN 38 THEN 16 * INTERVAL '1 hour'
WHEN 39 THEN 22 * INTERVAL '1 hour'
WHEN 40 THEN 24 * INTERVAL '1 hour'
END,
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 40
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments')
ON CONFLICT DO NOTHING;
-- =============================================
-- CREATE AIRDRYING PHASE RECORDS FOR MEYER EXPERIMENTS
-- =============================================
-- Create airdrying records for Meyer experiments (1-40)
INSERT INTO public.airdrying (
experiment_number,
experiment_phase_id,
scheduled_start_time,
duration_minutes,
scheduled_end_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days', -- Start 2 days after soaking
CASE e.experiment_number
WHEN 1 THEN 28 -- 28 minutes
WHEN 2 THEN 17 -- 17 minutes
WHEN 3 THEN 50 -- 50 minutes
WHEN 4 THEN 30 -- 30 minutes
WHEN 5 THEN 19 -- 19 minutes
WHEN 6 THEN 40 -- 40 minutes
WHEN 7 THEN 59 -- 59 minutes
WHEN 8 THEN 32 -- 32 minutes
WHEN 9 THEN 31 -- 31 minutes
WHEN 10 THEN 12 -- 12 minutes
WHEN 11 THEN 36 -- 36 minutes
WHEN 12 THEN 35 -- 35 minutes
WHEN 13 THEN 15 -- 15 minutes
WHEN 14 THEN 22 -- 22 minutes
WHEN 15 THEN 15 -- 15 minutes
WHEN 16 THEN 48 -- 48 minutes
WHEN 17 THEN 38 -- 38 minutes
WHEN 18 THEN 51 -- 51 minutes
WHEN 19 THEN 57 -- 57 minutes
WHEN 20 THEN 27 -- 27 minutes
WHEN 21 THEN 43 -- 43 minutes
WHEN 22 THEN 42 -- 42 minutes
WHEN 23 THEN 21 -- 21 minutes
WHEN 24 THEN 46 -- 46 minutes
WHEN 25 THEN 54 -- 54 minutes
WHEN 26 THEN 54 -- 54 minutes
WHEN 27 THEN 48 -- 48 minutes
WHEN 28 THEN 53 -- 53 minutes
WHEN 29 THEN 39 -- 39 minutes
WHEN 30 THEN 38 -- 38 minutes
WHEN 31 THEN 25 -- 25 minutes
WHEN 32 THEN 22 -- 22 minutes
WHEN 33 THEN 11 -- 11 minutes
WHEN 34 THEN 32 -- 32 minutes
WHEN 35 THEN 18 -- 18 minutes
WHEN 36 THEN 52 -- 52 minutes
WHEN 37 THEN 56 -- 56 minutes
WHEN 38 THEN 45 -- 45 minutes
WHEN 39 THEN 25 -- 25 minutes
WHEN 40 THEN 13 -- 13 minutes
END,
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days' +
CASE e.experiment_number
WHEN 1 THEN 28 * INTERVAL '1 minute' -- 28 minutes
WHEN 2 THEN 17 * INTERVAL '1 minute' -- 17 minutes
WHEN 3 THEN 50 * INTERVAL '1 minute' -- 50 minutes
WHEN 4 THEN 30 * INTERVAL '1 minute' -- 30 minutes
WHEN 5 THEN 19 * INTERVAL '1 minute' -- 19 minutes
WHEN 6 THEN 40 * INTERVAL '1 minute' -- 40 minutes
WHEN 7 THEN 59 * INTERVAL '1 minute' -- 59 minutes
WHEN 8 THEN 32 * INTERVAL '1 minute' -- 32 minutes
WHEN 9 THEN 31 * INTERVAL '1 minute' -- 31 minutes
WHEN 10 THEN 12 * INTERVAL '1 minute' -- 12 minutes
WHEN 11 THEN 36 * INTERVAL '1 minute' -- 36 minutes
WHEN 12 THEN 35 * INTERVAL '1 minute' -- 35 minutes
WHEN 13 THEN 15 * INTERVAL '1 minute' -- 15 minutes
WHEN 14 THEN 22 * INTERVAL '1 minute' -- 22 minutes
WHEN 15 THEN 15 * INTERVAL '1 minute' -- 15 minutes
WHEN 16 THEN 48 * INTERVAL '1 minute' -- 48 minutes
WHEN 17 THEN 38 * INTERVAL '1 minute' -- 38 minutes
WHEN 18 THEN 51 * INTERVAL '1 minute' -- 51 minutes
WHEN 19 THEN 57 * INTERVAL '1 minute' -- 57 minutes
WHEN 20 THEN 27 * INTERVAL '1 minute' -- 27 minutes
WHEN 21 THEN 43 * INTERVAL '1 minute' -- 43 minutes
WHEN 22 THEN 42 * INTERVAL '1 minute' -- 42 minutes
WHEN 23 THEN 21 * INTERVAL '1 minute' -- 21 minutes
WHEN 24 THEN 46 * INTERVAL '1 minute' -- 46 minutes
WHEN 25 THEN 54 * INTERVAL '1 minute' -- 54 minutes
WHEN 26 THEN 54 * INTERVAL '1 minute' -- 54 minutes
WHEN 27 THEN 48 * INTERVAL '1 minute' -- 48 minutes
WHEN 28 THEN 53 * INTERVAL '1 minute' -- 53 minutes
WHEN 29 THEN 39 * INTERVAL '1 minute' -- 39 minutes
WHEN 30 THEN 38 * INTERVAL '1 minute' -- 38 minutes
WHEN 31 THEN 25 * INTERVAL '1 minute' -- 25 minutes
WHEN 32 THEN 22 * INTERVAL '1 minute' -- 22 minutes
WHEN 33 THEN 11 * INTERVAL '1 minute' -- 11 minutes
WHEN 34 THEN 32 * INTERVAL '1 minute' -- 32 minutes
WHEN 35 THEN 18 * INTERVAL '1 minute' -- 18 minutes
WHEN 36 THEN 52 * INTERVAL '1 minute' -- 52 minutes
WHEN 37 THEN 56 * INTERVAL '1 minute' -- 56 minutes
WHEN 38 THEN 45 * INTERVAL '1 minute' -- 45 minutes
WHEN 39 THEN 25 * INTERVAL '1 minute' -- 25 minutes
WHEN 40 THEN 13 * INTERVAL '1 minute' -- 13 minutes
END,
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 40
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments')
ON CONFLICT DO NOTHING;
-- =============================================
-- CREATE CRACKING PHASE RECORDS FOR MEYER EXPERIMENTS
-- =============================================
-- Create cracking records for Meyer experiments (1-40)
INSERT INTO public.cracking (
experiment_number,
experiment_phase_id,
machine_type_id,
scheduled_start_time,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
(SELECT id FROM public.machine_types WHERE name = 'Meyer Cracker'),
NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '3 days', -- Start 3 days after soaking
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 40
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments')
ON CONFLICT DO NOTHING;
-- =============================================
-- CREATE MEYER CRACKER PARAMETERS FOR MEYER EXPERIMENTS
-- =============================================
-- Create Meyer cracker parameters for Meyer experiments (1-40)
INSERT INTO public.meyer_cracker_parameters (
cracking_id,
motor_speed_hz,
jig_displacement_inches,
spring_stiffness_nm
)
SELECT
c.id,
CASE e.experiment_number
WHEN 1 THEN 33.0
WHEN 2 THEN 30.0
WHEN 3 THEN 47.0
WHEN 4 THEN 42.0
WHEN 5 THEN 53.0
WHEN 6 THEN 37.0
WHEN 7 THEN 40.0
WHEN 8 THEN 39.0
WHEN 9 THEN 49.0
WHEN 10 THEN 47.0
WHEN 11 THEN 52.0
WHEN 12 THEN 59.0
WHEN 13 THEN 41.0
WHEN 14 THEN 46.0
WHEN 15 THEN 50.0
WHEN 16 THEN 36.0
WHEN 17 THEN 33.0
WHEN 18 THEN 35.0
WHEN 19 THEN 55.0
WHEN 20 THEN 44.0
WHEN 21 THEN 37.0
WHEN 22 THEN 56.0
WHEN 23 THEN 30.0
WHEN 24 THEN 60.0
WHEN 25 THEN 41.0
WHEN 26 THEN 55.0
WHEN 27 THEN 39.0
WHEN 28 THEN 34.0
WHEN 29 THEN 57.0
WHEN 30 THEN 45.0
WHEN 31 THEN 52.0
WHEN 32 THEN 51.0
WHEN 33 THEN 36.0
WHEN 34 THEN 44.0
WHEN 35 THEN 58.0
WHEN 36 THEN 32.0
WHEN 37 THEN 43.0
WHEN 38 THEN 60.0
WHEN 39 THEN 54.0
WHEN 40 THEN 48.0
END,
CASE e.experiment_number
WHEN 1 THEN -0.307
WHEN 2 THEN -0.311
WHEN 3 THEN -0.291
WHEN 4 THEN -0.314
WHEN 5 THEN -0.302
WHEN 6 THEN -0.301
WHEN 7 THEN -0.286
WHEN 8 THEN -0.309
WHEN 9 THEN -0.299
WHEN 10 THEN -0.295
WHEN 11 THEN -0.302
WHEN 12 THEN -0.299
WHEN 13 THEN -0.312
WHEN 14 THEN -0.303
WHEN 15 THEN -0.308
WHEN 16 THEN -0.306
WHEN 17 THEN -0.308
WHEN 18 THEN -0.311
WHEN 19 THEN -0.304
WHEN 20 THEN -0.313
WHEN 21 THEN -0.294
WHEN 22 THEN -0.310
WHEN 23 THEN -0.292
WHEN 24 THEN -0.294
WHEN 25 THEN -0.306
WHEN 26 THEN -0.296
WHEN 27 THEN -0.293
WHEN 28 THEN -0.285
WHEN 29 THEN -0.291
WHEN 30 THEN -0.296
WHEN 31 THEN -0.297
WHEN 32 THEN -0.288
WHEN 33 THEN -0.290
WHEN 34 THEN -0.315
WHEN 35 THEN -0.289
WHEN 36 THEN -0.288
WHEN 37 THEN -0.287
WHEN 38 THEN -0.298
WHEN 39 THEN -0.301
WHEN 40 THEN -0.305
END,
CASE e.experiment_number
WHEN 1 THEN 1800.0
WHEN 2 THEN 2000.0
WHEN 3 THEN 1800.0
WHEN 4 THEN 2000.0
WHEN 5 THEN 1800.0
WHEN 6 THEN 2200.0
WHEN 7 THEN 2000.0
WHEN 8 THEN 1800.0
WHEN 9 THEN 2200.0
WHEN 10 THEN 2000.0
WHEN 11 THEN 2000.0
WHEN 12 THEN 1800.0
WHEN 13 THEN 2000.0
WHEN 14 THEN 1800.0
WHEN 15 THEN 1800.0
WHEN 16 THEN 2200.0
WHEN 17 THEN 2200.0
WHEN 18 THEN 1800.0
WHEN 19 THEN 2000.0
WHEN 20 THEN 2200.0
WHEN 21 THEN 2000.0
WHEN 22 THEN 2200.0
WHEN 23 THEN 2200.0
WHEN 24 THEN 2200.0
WHEN 25 THEN 2000.0
WHEN 26 THEN 1800.0
WHEN 27 THEN 2200.0
WHEN 28 THEN 2200.0
WHEN 29 THEN 1800.0
WHEN 30 THEN 2200.0
WHEN 31 THEN 1800.0
WHEN 32 THEN 2200.0
WHEN 33 THEN 2000.0
WHEN 34 THEN 1800.0
WHEN 35 THEN 1800.0
WHEN 36 THEN 1800.0
WHEN 37 THEN 2200.0
WHEN 38 THEN 2200.0
WHEN 39 THEN 2000.0
WHEN 40 THEN 2000.0
END
FROM public.experiments e
JOIN public.cracking c ON c.experiment_number = e.experiment_number AND c.experiment_phase_id = e.phase_id
WHERE e.experiment_number BETWEEN 1 AND 40
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments')
ON CONFLICT DO NOTHING;
-- =============================================
-- CREATE EXPERIMENT REPETITIONS FOR MEYER EXPERIMENTS
-- =============================================
-- Create experiment repetitions for Meyer experiments
-- Each experiment needs only 1 repetition
INSERT INTO public.experiment_repetitions (
experiment_number,
experiment_phase_id,
repetition_number,
status,
created_by
)
SELECT
e.experiment_number,
e.phase_id,
1,
'pending',
e.created_by
FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 40
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments')
ON CONFLICT DO NOTHING;

View File

@@ -546,3 +546,4 @@ FROM public.experiments e
WHERE e.experiment_number BETWEEN 1 AND 40
AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments')
ON CONFLICT DO NOTHING;