Refactor Supabase services in docker-compose.yml for better organization and testing

- Commented out all Supabase services to facilitate testing with Supabase CLI.
- Updated README to include Supabase directory in project structure.
- Adjusted documentation for migration paths in Supabase Docker Compose guide.
- Enhanced docker-compose-reset.sh to explicitly remove Supabase volumes and wait for migrations to complete.
This commit is contained in:
salirezav
2025-12-18 18:27:04 -05:00
parent 93c68768d8
commit 8cb45cbe03
28 changed files with 7264 additions and 253 deletions

View File

@@ -0,0 +1,87 @@
-- Extensions and Utility Functions
-- This migration creates required extensions and utility functions used across the database
-- =============================================
-- 1. EXTENSIONS
-- =============================================
-- Enable UUID generation
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Enable password hashing
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
-- =============================================
-- 2. 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;

View File

@@ -0,0 +1,237 @@
-- Users and Roles
-- This migration creates user-related tables with clean separation
-- =============================================
-- 1. 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()
);
-- =============================================
-- 2. 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()
);
-- =============================================
-- 3. 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)
);
-- =============================================
-- 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();
-- Create trigger for updated_at on roles
CREATE TRIGGER set_updated_at_roles
BEFORE UPDATE ON public.roles
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');
-- =============================================
-- 9. USER MANAGEMENT FUNCTIONS
-- =============================================
-- Function to create a new user with roles
CREATE OR REPLACE FUNCTION public.create_user_with_roles(
user_email TEXT,
role_names TEXT[],
temp_password TEXT
)
RETURNS JSON AS $$
DECLARE
new_user_id UUID;
encrypted_pwd TEXT;
role_name TEXT;
role_id_val UUID;
assigned_by_id UUID;
result JSON;
user_roles_array TEXT[];
BEGIN
-- Generate new user ID
new_user_id := uuid_generate_v4();
-- Encrypt the password
encrypted_pwd := crypt(temp_password, gen_salt('bf'));
-- Get the current user ID for assigned_by, but only if they have a profile
-- Otherwise, use the new user ID (which we'll create next)
SELECT id INTO assigned_by_id
FROM public.user_profiles
WHERE id = auth.uid();
-- If no valid assigned_by user found, use the new user ID (self-assigned)
IF assigned_by_id IS NULL THEN
assigned_by_id := new_user_id;
END IF;
-- Create user in auth.users
INSERT INTO auth.users (
instance_id,
id,
aud,
role,
email,
encrypted_password,
email_confirmed_at,
created_at,
updated_at,
confirmation_token,
email_change,
email_change_token_new,
recovery_token
) VALUES (
'00000000-0000-0000-0000-000000000000',
new_user_id,
'authenticated',
'authenticated',
user_email,
encrypted_pwd,
NOW(),
NOW(),
NOW(),
'',
'',
'',
''
);
-- Create user profile
INSERT INTO public.user_profiles (id, email, status)
VALUES (new_user_id, user_email, 'active');
-- Assign roles
user_roles_array := ARRAY[]::TEXT[];
FOREACH role_name IN ARRAY role_names
LOOP
-- Get role ID
SELECT id INTO role_id_val
FROM public.roles
WHERE name = role_name;
-- If role exists, assign it
IF role_id_val IS NOT NULL THEN
INSERT INTO public.user_roles (user_id, role_id, assigned_by)
VALUES (new_user_id, role_id_val, assigned_by_id)
ON CONFLICT (user_id, role_id) DO NOTHING;
-- Add to roles array for return value
user_roles_array := array_append(user_roles_array, role_name);
END IF;
END LOOP;
-- Return the result as JSON
result := json_build_object(
'user_id', new_user_id::TEXT,
'email', user_email,
'temp_password', temp_password,
'roles', user_roles_array,
'status', 'active'
);
RETURN result;
EXCEPTION
WHEN unique_violation THEN
RAISE EXCEPTION 'User with email % already exists', user_email;
WHEN OTHERS THEN
RAISE EXCEPTION 'Error creating user: %', SQLERRM;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Grant execute permission on the function
GRANT EXECUTE ON FUNCTION public.create_user_with_roles(TEXT, TEXT[], TEXT) TO authenticated;
-- Comment for documentation
COMMENT ON FUNCTION public.create_user_with_roles(TEXT, TEXT[], TEXT) IS
'Creates a new user in auth.users, creates a profile in user_profiles, and assigns the specified roles. Returns user information including user_id, email, temp_password, roles, and status.';

View File

@@ -0,0 +1,63 @@
-- Machine Types
-- This migration creates the machine types table
-- =============================================
-- 1. 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. INDEXES FOR PERFORMANCE
-- =============================================
CREATE INDEX IF NOT EXISTS idx_machine_types_name ON public.machine_types(name);
-- =============================================
-- 3. 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();
-- =============================================
-- 4. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.machine_types TO authenticated;
-- =============================================
-- 5. ENABLE ROW LEVEL SECURITY
-- =============================================
ALTER TABLE public.machine_types ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 6. CREATE RLS POLICIES
-- =============================================
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');

View File

@@ -0,0 +1,77 @@
-- Experiment Phases
-- This migration creates the experiment phases table
-- =============================================
-- 1. 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))
);
-- =============================================
-- 2. INDEXES FOR PERFORMANCE
-- =============================================
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);
-- =============================================
-- 3. TRIGGERS
-- =============================================
-- 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();
-- =============================================
-- 4. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.experiment_phases TO authenticated;
-- =============================================
-- 5. ENABLE ROW LEVEL SECURITY
-- =============================================
ALTER TABLE public.experiment_phases ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 6. CREATE RLS POLICIES
-- =============================================
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,70 @@
-- Experiments
-- This migration creates the experiments table
-- =============================================
-- 1. EXPERIMENTS TABLE
-- =============================================
CREATE TABLE IF NOT EXISTS public.experiments (
id UUID PRIMARY KEY 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),
-- Ensure unique combination of experiment_number and phase_id
CONSTRAINT unique_experiment_number_phase UNIQUE (experiment_number, phase_id)
);
-- =============================================
-- 2. 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_experiments_id ON public.experiments(id);
-- =============================================
-- 3. 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();
-- =============================================
-- 4. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.experiments TO authenticated;
-- =============================================
-- 5. ENABLE ROW LEVEL SECURITY
-- =============================================
ALTER TABLE public.experiments ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 6. CREATE RLS POLICIES
-- =============================================
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');

View File

@@ -0,0 +1,69 @@
-- Experiment Repetitions
-- This migration creates the experiment repetitions table
-- =============================================
-- 1. 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),
scheduled_date TIMESTAMP WITH TIME ZONE,
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)
);
-- =============================================
-- 2. INDEXES FOR PERFORMANCE
-- =============================================
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_id ON public.experiment_repetitions(experiment_id);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_created_by ON public.experiment_repetitions(created_by);
-- =============================================
-- 3. TRIGGERS
-- =============================================
-- 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();
-- =============================================
-- 4. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.experiment_repetitions TO authenticated;
-- =============================================
-- 5. ENABLE ROW LEVEL SECURITY
-- =============================================
ALTER TABLE public.experiment_repetitions ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 6. CREATE RLS POLICIES
-- =============================================
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,89 @@
-- Cracker Parameters
-- This migration creates machine-specific parameter tables (must be created before cracking table)
-- =============================================
-- 1. JC CRACKER PARAMETERS TABLE
-- =============================================
CREATE TABLE IF NOT EXISTS public.jc_cracker_parameters (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
plate_contact_frequency_hz DOUBLE PRECISION NOT NULL CHECK (plate_contact_frequency_hz > 0),
throughput_rate_pecans_sec DOUBLE PRECISION NOT NULL CHECK (throughput_rate_pecans_sec > 0),
crush_amount_in DOUBLE PRECISION NOT NULL CHECK (crush_amount_in >= 0),
entry_exit_height_diff_in DOUBLE PRECISION NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- =============================================
-- 2. MEYER CRACKER PARAMETERS TABLE
-- =============================================
CREATE TABLE IF NOT EXISTS public.meyer_cracker_parameters (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
motor_speed_hz DOUBLE PRECISION NOT NULL CHECK (motor_speed_hz > 0),
jig_displacement_inches DOUBLE PRECISION NOT NULL,
spring_stiffness_nm DOUBLE PRECISION NOT NULL CHECK (spring_stiffness_nm > 0),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- =============================================
-- 3. TRIGGERS
-- =============================================
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();
-- =============================================
-- 4. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.jc_cracker_parameters TO authenticated;
GRANT ALL ON public.meyer_cracker_parameters TO authenticated;
-- =============================================
-- 5. ENABLE ROW LEVEL SECURITY
-- =============================================
ALTER TABLE public.jc_cracker_parameters ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.meyer_cracker_parameters ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 6. CREATE RLS POLICIES
-- =============================================
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,274 @@
-- Phase Data Tables
-- This migration creates phase-specific data entry tables (soaking, airdrying, cracking, shelling)
-- =============================================
-- 1. SOAKING TABLE
-- =============================================
CREATE TABLE IF NOT EXISTS public.soaking (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
repetition_id UUID NOT NULL 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 repetition
CONSTRAINT unique_soaking_per_repetition UNIQUE (repetition_id)
);
-- =============================================
-- 2. AIRDRYING TABLE
-- =============================================
CREATE TABLE IF NOT EXISTS public.airdrying (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
repetition_id UUID NOT NULL 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 repetition
CONSTRAINT unique_airdrying_per_repetition UNIQUE (repetition_id)
);
-- =============================================
-- 3. CRACKING TABLE
-- =============================================
CREATE TABLE IF NOT EXISTS public.cracking (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
repetition_id UUID NOT NULL 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 repetition
CONSTRAINT unique_cracking_per_repetition UNIQUE (repetition_id)
);
-- =============================================
-- 4. SHELLING TABLE
-- =============================================
CREATE TABLE IF NOT EXISTS public.shelling (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
repetition_id UUID NOT NULL 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 repetition
CONSTRAINT unique_shelling_per_repetition UNIQUE (repetition_id)
);
-- =============================================
-- 5. INDEXES FOR PERFORMANCE
-- =============================================
-- 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);
-- =============================================
-- 6. TRIGGER FUNCTIONS 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;
-- 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;
-- 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 for the same repetition
IF NEW.scheduled_start_time IS NULL THEN
SELECT s.scheduled_end_time INTO NEW.scheduled_start_time
FROM public.soaking s
WHERE s.repetition_id = NEW.repetition_id
LIMIT 1;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- 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 for the same repetition
IF NEW.scheduled_start_time IS NULL THEN
SELECT a.scheduled_end_time INTO NEW.scheduled_start_time
FROM public.airdrying a
WHERE a.repetition_id = NEW.repetition_id
LIMIT 1;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- =============================================
-- 7. TRIGGERS
-- =============================================
-- Triggers for automatic timestamp calculations
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();
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();
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();
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();
-- 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();
-- =============================================
-- 8. 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;
-- =============================================
-- 9. 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;
-- =============================================
-- 10. 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');

View File

@@ -0,0 +1,193 @@
-- Conductor Availability
-- This migration creates the conductor availability table
-- =============================================
-- 1. CONDUCTOR AVAILABILITY TABLE
-- =============================================
CREATE TABLE IF NOT EXISTS public.conductor_availability (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID NOT NULL REFERENCES public.user_profiles(id) ON DELETE CASCADE,
available_from TIMESTAMP WITH TIME ZONE NOT NULL,
available_to TIMESTAMP WITH TIME ZONE NOT NULL,
notes TEXT, -- Optional notes about the availability
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', '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 available_to is after available_from
CONSTRAINT valid_time_range CHECK (available_to > available_from),
-- Ensure availability is in the future (can be modified if needed for past records)
CONSTRAINT future_availability CHECK (available_from >= NOW() - INTERVAL '1 day')
);
-- =============================================
-- 2. INDEXES FOR PERFORMANCE
-- =============================================
CREATE INDEX IF NOT EXISTS idx_conductor_availability_user_id ON public.conductor_availability(user_id);
CREATE INDEX IF NOT EXISTS idx_conductor_availability_available_from ON public.conductor_availability(available_from);
CREATE INDEX IF NOT EXISTS idx_conductor_availability_available_to ON public.conductor_availability(available_to);
CREATE INDEX IF NOT EXISTS idx_conductor_availability_status ON public.conductor_availability(status);
CREATE INDEX IF NOT EXISTS idx_conductor_availability_created_by ON public.conductor_availability(created_by);
CREATE INDEX IF NOT EXISTS idx_conductor_availability_time_range ON public.conductor_availability(available_from, available_to);
-- =============================================
-- 3. FUNCTIONS FOR OVERLAP PREVENTION
-- =============================================
-- Function to check for overlapping availabilities
CREATE OR REPLACE FUNCTION public.check_availability_overlap()
RETURNS TRIGGER AS $$
DECLARE
overlap_count INTEGER;
BEGIN
-- Check for overlapping availabilities for the same user
SELECT COUNT(*) INTO overlap_count
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 availability starts during an existing one
(NEW.available_from >= available_from AND NEW.available_from < available_to) OR
-- New availability ends during an existing one
(NEW.available_to > available_from AND NEW.available_to <= available_to) OR
-- New availability completely contains an existing one
(NEW.available_from <= available_from AND NEW.available_to >= available_to) OR
-- Existing availability completely contains the new one
(available_from <= NEW.available_from AND available_to >= NEW.available_to)
);
IF overlap_count > 0 THEN
RAISE EXCEPTION 'Availability overlaps with existing availability for user %. Please adjust the time range or cancel the conflicting availability.', NEW.user_id;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Function to get available conductors for a specific time range
CREATE OR REPLACE FUNCTION public.get_available_conductors(
start_time TIMESTAMP WITH TIME ZONE,
end_time TIMESTAMP WITH TIME ZONE
)
RETURNS TABLE (
user_id UUID,
email TEXT,
available_from TIMESTAMP WITH TIME ZONE,
available_to TIMESTAMP WITH TIME ZONE
) AS $$
BEGIN
RETURN QUERY
SELECT
ca.user_id,
up.email,
ca.available_from,
ca.available_to
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'
AND ca.available_from <= start_time
AND ca.available_to >= end_time
ORDER BY up.email;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Function to check if a conductor is available for a specific time range
CREATE OR REPLACE FUNCTION public.is_conductor_available(
conductor_user_id UUID,
start_time TIMESTAMP WITH TIME ZONE,
end_time TIMESTAMP WITH TIME ZONE
)
RETURNS BOOLEAN AS $$
DECLARE
availability_count INTEGER;
BEGIN
SELECT COUNT(*) INTO availability_count
FROM public.conductor_availability
WHERE user_id = conductor_user_id
AND status = 'active'
AND available_from <= start_time
AND available_to >= end_time;
RETURN availability_count > 0;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- =============================================
-- 4. 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 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();
-- =============================================
-- 5. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.conductor_availability TO authenticated;
-- =============================================
-- 6. ENABLE ROW LEVEL SECURITY
-- =============================================
ALTER TABLE public.conductor_availability ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 7. CREATE RLS POLICIES
-- =============================================
CREATE POLICY "conductor_availability_select_policy" ON public.conductor_availability
FOR SELECT
TO authenticated
USING (
-- Users can view their own availability, admins can view all
user_id = auth.uid() OR public.is_admin()
);
CREATE POLICY "conductor_availability_insert_policy" ON public.conductor_availability
FOR INSERT
TO authenticated
WITH CHECK (
-- Users can create their own availability, admins can create for anyone
(user_id = auth.uid() AND created_by = auth.uid()) OR public.is_admin()
);
CREATE POLICY "conductor_availability_update_policy" ON public.conductor_availability
FOR UPDATE
TO authenticated
USING (
-- Users can update their own availability, admins can update any
user_id = auth.uid() OR public.is_admin()
)
WITH CHECK (
-- Users can update their own availability, admins can update any
user_id = auth.uid() OR public.is_admin()
);
CREATE POLICY "conductor_availability_delete_policy" ON public.conductor_availability
FOR DELETE
TO authenticated
USING (
-- Users can delete their own availability, admins can delete any
user_id = auth.uid() OR public.is_admin()
);

View File

@@ -0,0 +1,195 @@
-- Views
-- This migration creates views for easier querying (must run last after all tables are created)
-- =============================================
-- 1. CREATE VIEWS FOR EASIER QUERYING
-- =============================================
-- View for experiments with all phase information
-- Note: Since phases are now per-repetition, this view shows phase data from the first repetition
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.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,
er.id as first_repetition_id,
er.repetition_number as first_repetition_number,
s.id as soaking_id,
s.scheduled_start_time as soaking_scheduled_start,
s.actual_start_time as soaking_actual_start,
s.soaking_duration_minutes,
s.scheduled_end_time as soaking_scheduled_end,
s.actual_end_time as soaking_actual_end,
ad.id as airdrying_id,
ad.scheduled_start_time as airdrying_scheduled_start,
ad.actual_start_time as airdrying_actual_start,
ad.duration_minutes as airdrying_duration,
ad.scheduled_end_time as airdrying_scheduled_end,
ad.actual_end_time as airdrying_actual_end,
c.id as cracking_id,
c.scheduled_start_time as cracking_scheduled_start,
c.actual_start_time as cracking_actual_start,
c.actual_end_time as cracking_actual_end,
mt.name as machine_type_name,
sh.id as shelling_id,
sh.scheduled_start_time as shelling_scheduled_start,
sh.actual_start_time as shelling_actual_start,
sh.actual_end_time as shelling_actual_end
FROM public.experiments e
LEFT JOIN public.experiment_phases ep ON e.phase_id = ep.id
LEFT JOIN LATERAL (
SELECT id, repetition_number
FROM public.experiment_repetitions
WHERE experiment_id = e.id
ORDER BY repetition_number
LIMIT 1
) er ON true
LEFT JOIN public.soaking s ON s.repetition_id = er.id
LEFT JOIN public.airdrying ad ON ad.repetition_id = er.id
LEFT JOIN public.cracking c ON c.repetition_id = er.id
LEFT JOIN public.machine_types mt ON c.machine_type_id = mt.id
LEFT JOIN public.shelling sh ON sh.repetition_id = er.id;
-- View for repetitions with phase information
CREATE OR REPLACE VIEW public.repetitions_with_phases AS
SELECT
er.id,
er.experiment_id,
er.repetition_number,
er.status,
er.created_at,
er.updated_at,
er.created_by,
e.experiment_number,
e.phase_id,
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;
-- 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.available_conductors TO authenticated;
-- =============================================
-- 3. 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.available_conductors IS 'View of currently available conductors with their profile information';
-- =============================================
-- 4. 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

@@ -0,0 +1,300 @@
-- Unified Phase Executions Table
-- This migration replaces the separate phase tables (soaking, airdrying, cracking, shelling)
-- with a unified table that properly supports repetitions
-- =============================================
-- 1. CREATE UNIFIED PHASE EXECUTIONS TABLE
-- =============================================
CREATE TABLE IF NOT EXISTS public.experiment_phase_executions (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
repetition_id UUID NOT NULL REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE,
phase_type TEXT NOT NULL CHECK (phase_type IN ('soaking', 'airdrying', 'cracking', 'shelling')),
-- Scheduling fields (common to all phases)
scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL,
scheduled_end_time TIMESTAMP WITH TIME ZONE,
actual_start_time TIMESTAMP WITH TIME ZONE,
actual_end_time TIMESTAMP WITH TIME ZONE,
-- Phase-specific parameters (nullable, only relevant for specific phases)
-- Soaking
soaking_duration_minutes INTEGER CHECK (soaking_duration_minutes > 0),
-- Airdrying
duration_minutes INTEGER CHECK (duration_minutes > 0),
-- Cracking
machine_type_id UUID REFERENCES public.machine_types(id),
-- Status tracking
status TEXT NOT NULL DEFAULT 'pending'
CHECK (status IN ('pending', 'scheduled', '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 one execution per phase type per repetition
CONSTRAINT unique_phase_per_repetition UNIQUE (repetition_id, phase_type)
);
-- =============================================
-- 2. INDEXES FOR PERFORMANCE
-- =============================================
CREATE INDEX IF NOT EXISTS idx_phase_executions_repetition_id
ON public.experiment_phase_executions(repetition_id);
CREATE INDEX IF NOT EXISTS idx_phase_executions_phase_type
ON public.experiment_phase_executions(phase_type);
CREATE INDEX IF NOT EXISTS idx_phase_executions_status
ON public.experiment_phase_executions(status);
CREATE INDEX IF NOT EXISTS idx_phase_executions_scheduled_start_time
ON public.experiment_phase_executions(scheduled_start_time);
CREATE INDEX IF NOT EXISTS idx_phase_executions_machine_type_id
ON public.experiment_phase_executions(machine_type_id);
CREATE INDEX IF NOT EXISTS idx_phase_executions_created_by
ON public.experiment_phase_executions(created_by);
-- =============================================
-- 3. FUNCTION: Calculate Sequential Phase Start Times
-- =============================================
CREATE OR REPLACE FUNCTION calculate_sequential_phase_start_time()
RETURNS TRIGGER AS $$
DECLARE
prev_phase_end_time TIMESTAMP WITH TIME ZONE;
phase_order TEXT[] := ARRAY['soaking', 'airdrying', 'cracking', 'shelling'];
current_phase_index INT;
prev_phase_name TEXT;
BEGIN
-- Find current phase index in the sequence
SELECT array_position(phase_order, NEW.phase_type) INTO current_phase_index;
-- If not the first phase, get previous phase's end time from the same repetition
IF current_phase_index > 1 THEN
prev_phase_name := phase_order[current_phase_index - 1];
SELECT scheduled_end_time INTO prev_phase_end_time
FROM public.experiment_phase_executions
WHERE repetition_id = NEW.repetition_id
AND phase_type = prev_phase_name
ORDER BY created_at DESC
LIMIT 1;
-- If previous phase exists and has an end time, use it as start time
IF prev_phase_end_time IS NOT NULL THEN
NEW.scheduled_start_time := prev_phase_end_time;
END IF;
END IF;
-- Calculate end time based on duration (for phases with duration)
IF NEW.phase_type = 'soaking' AND NEW.soaking_duration_minutes IS NOT NULL THEN
NEW.scheduled_end_time := NEW.scheduled_start_time +
(NEW.soaking_duration_minutes || ' minutes')::INTERVAL;
ELSIF NEW.phase_type = 'airdrying' AND NEW.duration_minutes IS NOT NULL THEN
NEW.scheduled_end_time := NEW.scheduled_start_time +
(NEW.duration_minutes || ' minutes')::INTERVAL;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- =============================================
-- 4. FUNCTION: Auto-create Phase Executions for New Repetition
-- =============================================
CREATE OR REPLACE FUNCTION create_phase_executions_for_repetition()
RETURNS TRIGGER AS $$
DECLARE
exp_phase_config RECORD;
phase_type_list TEXT[] := ARRAY[]::TEXT[];
phase_name TEXT;
BEGIN
-- Get experiment phase configuration
-- Note: Phase durations may need to be set later when scheduling
SELECT
ep.has_soaking,
ep.has_airdrying,
ep.has_cracking,
ep.has_shelling,
ep.cracking_machine_type_id
INTO exp_phase_config
FROM public.experiments e
JOIN public.experiment_phases ep ON e.phase_id = ep.id
WHERE e.id = NEW.experiment_id;
-- Build list of phases to create based on experiment configuration
IF exp_phase_config.has_soaking THEN
phase_type_list := array_append(phase_type_list, 'soaking');
END IF;
IF exp_phase_config.has_airdrying THEN
phase_type_list := array_append(phase_type_list, 'airdrying');
END IF;
IF exp_phase_config.has_cracking THEN
phase_type_list := array_append(phase_type_list, 'cracking');
END IF;
IF exp_phase_config.has_shelling THEN
phase_type_list := array_append(phase_type_list, 'shelling');
END IF;
-- Create phase executions for each required phase
FOREACH phase_name IN ARRAY phase_type_list
LOOP
INSERT INTO public.experiment_phase_executions (
repetition_id,
phase_type,
scheduled_start_time,
status,
created_by,
-- Phase-specific parameters
soaking_duration_minutes,
duration_minutes,
machine_type_id
)
VALUES (
NEW.id,
phase_name,
NOW(), -- Default start time, will be updated when scheduled or by sequential calculation
'pending',
NEW.created_by,
-- Set phase-specific parameters
-- Note: Durations will be set when the repetition is scheduled
-- These can be NULL initially and updated later
NULL, -- soaking_duration_minutes (set when scheduled)
NULL, -- duration_minutes (set when scheduled)
CASE WHEN phase_name = 'cracking'
THEN exp_phase_config.cracking_machine_type_id
ELSE NULL END
);
END LOOP;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- =============================================
-- 5. TRIGGERS
-- =============================================
-- Trigger to automatically calculate sequential times and durations
CREATE TRIGGER trigger_calculate_sequential_phase_times
BEFORE INSERT OR UPDATE ON public.experiment_phase_executions
FOR EACH ROW
EXECUTE FUNCTION calculate_sequential_phase_start_time();
-- Trigger to auto-create phases when repetition is created
CREATE TRIGGER trigger_create_phase_executions
AFTER INSERT ON public.experiment_repetitions
FOR EACH ROW
EXECUTE FUNCTION create_phase_executions_for_repetition();
-- Trigger for updated_at
CREATE TRIGGER set_updated_at_phase_executions
BEFORE UPDATE ON public.experiment_phase_executions
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- =============================================
-- 6. CREATE VIEWS FOR PHASE-SPECIFIC ACCESS (Backward Compatibility)
-- =============================================
-- These views allow existing code to work with phase-specific "tables"
CREATE OR REPLACE VIEW public.soaking_view AS
SELECT
id,
(SELECT experiment_id FROM experiment_repetitions WHERE id = repetition_id) as experiment_id,
repetition_id,
scheduled_start_time,
actual_start_time,
soaking_duration_minutes,
scheduled_end_time,
actual_end_time,
created_at,
updated_at,
created_by
FROM public.experiment_phase_executions
WHERE phase_type = 'soaking';
CREATE OR REPLACE VIEW public.airdrying_view AS
SELECT
id,
(SELECT experiment_id FROM experiment_repetitions WHERE id = repetition_id) as experiment_id,
repetition_id,
scheduled_start_time,
actual_start_time,
duration_minutes,
scheduled_end_time,
actual_end_time,
created_at,
updated_at,
created_by
FROM public.experiment_phase_executions
WHERE phase_type = 'airdrying';
CREATE OR REPLACE VIEW public.cracking_view AS
SELECT
id,
(SELECT experiment_id FROM experiment_repetitions WHERE id = repetition_id) as experiment_id,
repetition_id,
machine_type_id,
scheduled_start_time,
actual_start_time,
actual_end_time,
created_at,
updated_at,
created_by
FROM public.experiment_phase_executions
WHERE phase_type = 'cracking';
CREATE OR REPLACE VIEW public.shelling_view AS
SELECT
id,
(SELECT experiment_id FROM experiment_repetitions WHERE id = repetition_id) as experiment_id,
repetition_id,
scheduled_start_time,
actual_start_time,
actual_end_time,
created_at,
updated_at,
created_by
FROM public.experiment_phase_executions
WHERE phase_type = 'shelling';
-- =============================================
-- 7. GRANT PERMISSIONS
-- =============================================
GRANT ALL ON public.experiment_phase_executions TO authenticated;
GRANT SELECT ON public.soaking_view TO authenticated;
GRANT SELECT ON public.airdrying_view TO authenticated;
GRANT SELECT ON public.cracking_view TO authenticated;
GRANT SELECT ON public.shelling_view TO authenticated;
-- =============================================
-- 8. ENABLE ROW LEVEL SECURITY
-- =============================================
ALTER TABLE public.experiment_phase_executions ENABLE ROW LEVEL SECURITY;
-- =============================================
-- 9. CREATE RLS POLICIES
-- =============================================
CREATE POLICY "Phase executions are viewable by authenticated users"
ON public.experiment_phase_executions
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "Phase executions are insertable by authenticated users"
ON public.experiment_phase_executions
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Phase executions are updatable by authenticated users"
ON public.experiment_phase_executions
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "Phase executions are deletable by authenticated users"
ON public.experiment_phase_executions
FOR DELETE USING (auth.role() = 'authenticated');

View File

@@ -0,0 +1,46 @@
-- Add repetition_id foreign key to cracker parameters tables
-- This migration adds a foreign key to link cracker parameters to their repetitions
-- =============================================
-- 1. ADD REPETITION_ID TO JC CRACKER PARAMETERS
-- =============================================
ALTER TABLE public.jc_cracker_parameters
ADD COLUMN IF NOT EXISTS repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE;
-- Add index for performance
CREATE INDEX IF NOT EXISTS idx_jc_cracker_parameters_repetition_id
ON public.jc_cracker_parameters(repetition_id);
-- Add unique constraint to ensure one parameter set per repetition
ALTER TABLE public.jc_cracker_parameters
ADD CONSTRAINT unique_jc_cracker_parameters_per_repetition
UNIQUE (repetition_id);
-- =============================================
-- 2. ADD REPETITION_ID TO MEYER CRACKER PARAMETERS
-- =============================================
ALTER TABLE public.meyer_cracker_parameters
ADD COLUMN IF NOT EXISTS repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE;
-- Add index for performance
CREATE INDEX IF NOT EXISTS idx_meyer_cracker_parameters_repetition_id
ON public.meyer_cracker_parameters(repetition_id);
-- Add unique constraint to ensure one parameter set per repetition
ALTER TABLE public.meyer_cracker_parameters
ADD CONSTRAINT unique_meyer_cracker_parameters_per_repetition
UNIQUE (repetition_id);

View File

@@ -0,0 +1,277 @@
-- View: Experiments with All Repetitions and Phase Parameters
-- This view provides a comprehensive view of experiments with all their repetitions
-- and all phase execution parameters (soaking, airdrying, cracking, shelling)
CREATE OR REPLACE VIEW public.experiments_with_all_reps_and_phases AS
SELECT
-- Experiment fields
e.id as experiment_id,
e.experiment_number,
e.reps_required,
e.weight_per_repetition_lbs,
e.results_status,
e.completion_status,
e.phase_id,
e.created_at as experiment_created_at,
e.updated_at as experiment_updated_at,
e.created_by as experiment_created_by,
-- Phase information
ep.name as phase_name,
ep.description as phase_description,
ep.has_soaking,
ep.has_airdrying,
ep.has_cracking,
ep.has_shelling,
ep.cracking_machine_type_id as phase_cracking_machine_type_id,
-- Repetition fields
er.id as repetition_id,
er.repetition_number,
er.status as repetition_status,
er.scheduled_date,
er.created_at as repetition_created_at,
er.updated_at as repetition_updated_at,
er.created_by as repetition_created_by,
-- Soaking phase execution
soaking_e.id as soaking_execution_id,
soaking_e.scheduled_start_time as soaking_scheduled_start,
soaking_e.actual_start_time as soaking_actual_start,
soaking_e.soaking_duration_minutes,
soaking_e.scheduled_end_time as soaking_scheduled_end,
soaking_e.actual_end_time as soaking_actual_end,
soaking_e.status as soaking_status,
-- Airdrying phase execution
airdrying_e.id as airdrying_execution_id,
airdrying_e.scheduled_start_time as airdrying_scheduled_start,
airdrying_e.actual_start_time as airdrying_actual_start,
airdrying_e.duration_minutes as airdrying_duration_minutes,
airdrying_e.scheduled_end_time as airdrying_scheduled_end,
airdrying_e.actual_end_time as airdrying_actual_end,
airdrying_e.status as airdrying_status,
-- Cracking phase execution
cracking_e.id as cracking_execution_id,
cracking_e.scheduled_start_time as cracking_scheduled_start,
cracking_e.actual_start_time as cracking_actual_start,
cracking_e.scheduled_end_time as cracking_scheduled_end,
cracking_e.actual_end_time as cracking_actual_end,
cracking_e.machine_type_id as cracking_machine_type_id,
cracking_e.status as cracking_status,
mt.name as machine_type_name,
-- Shelling phase execution
shelling_e.id as shelling_execution_id,
shelling_e.scheduled_start_time as shelling_scheduled_start,
shelling_e.actual_start_time as shelling_actual_start,
shelling_e.scheduled_end_time as shelling_scheduled_end,
shelling_e.actual_end_time as shelling_actual_end,
shelling_e.status as shelling_status
FROM public.experiments e
LEFT JOIN public.experiment_phases ep ON e.phase_id = ep.id
LEFT JOIN public.experiment_repetitions er ON er.experiment_id = e.id
LEFT JOIN public.experiment_phase_executions soaking_e
ON soaking_e.repetition_id = er.id AND soaking_e.phase_type = 'soaking'
LEFT JOIN public.experiment_phase_executions airdrying_e
ON airdrying_e.repetition_id = er.id AND airdrying_e.phase_type = 'airdrying'
LEFT JOIN public.experiment_phase_executions cracking_e
ON cracking_e.repetition_id = er.id AND cracking_e.phase_type = 'cracking'
LEFT JOIN public.experiment_phase_executions shelling_e
ON shelling_e.repetition_id = er.id AND shelling_e.phase_type = 'shelling'
LEFT JOIN public.machine_types mt ON cracking_e.machine_type_id = mt.id
ORDER BY e.experiment_number, er.repetition_number;
-- Grant permissions
GRANT SELECT ON public.experiments_with_all_reps_and_phases TO authenticated;
-- Function: Get experiment with all repetitions and phase parameters
-- This function returns a JSON structure with experiment and all its repetitions
CREATE OR REPLACE FUNCTION public.get_experiment_with_reps_and_phases(p_experiment_id UUID)
RETURNS TABLE (
experiment_id UUID,
experiment_number INTEGER,
phase_name TEXT,
repetitions JSONB
) AS $$
BEGIN
RETURN QUERY
SELECT
e.id,
e.experiment_number,
ep.name,
COALESCE(
jsonb_agg(
jsonb_build_object(
'repetition_id', er.id,
'repetition_number', er.repetition_number,
'status', er.status,
'scheduled_date', er.scheduled_date,
'soaking', jsonb_build_object(
'scheduled_start', soaking_e.scheduled_start_time,
'actual_start', soaking_e.actual_start_time,
'duration_minutes', soaking_e.soaking_duration_minutes,
'scheduled_end', soaking_e.scheduled_end_time,
'actual_end', soaking_e.actual_end_time,
'status', soaking_e.status
),
'airdrying', jsonb_build_object(
'scheduled_start', airdrying_e.scheduled_start_time,
'actual_start', airdrying_e.actual_start_time,
'duration_minutes', airdrying_e.duration_minutes,
'scheduled_end', airdrying_e.scheduled_end_time,
'actual_end', airdrying_e.actual_end_time,
'status', airdrying_e.status
),
'cracking', jsonb_build_object(
'scheduled_start', cracking_e.scheduled_start_time,
'actual_start', cracking_e.actual_start_time,
'scheduled_end', cracking_e.scheduled_end_time,
'actual_end', cracking_e.actual_end_time,
'machine_type_id', cracking_e.machine_type_id,
'machine_type_name', mt.name,
'status', cracking_e.status
),
'shelling', jsonb_build_object(
'scheduled_start', shelling_e.scheduled_start_time,
'actual_start', shelling_e.actual_start_time,
'scheduled_end', shelling_e.scheduled_end_time,
'actual_end', shelling_e.actual_end_time,
'status', shelling_e.status
)
)
ORDER BY er.repetition_number
),
'[]'::jsonb
) as repetitions
FROM public.experiments e
LEFT JOIN public.experiment_phases ep ON e.phase_id = ep.id
LEFT JOIN public.experiment_repetitions er ON er.experiment_id = e.id
LEFT JOIN public.experiment_phase_executions soaking_e
ON soaking_e.repetition_id = er.id AND soaking_e.phase_type = 'soaking'
LEFT JOIN public.experiment_phase_executions airdrying_e
ON airdrying_e.repetition_id = er.id AND airdrying_e.phase_type = 'airdrying'
LEFT JOIN public.experiment_phase_executions cracking_e
ON cracking_e.repetition_id = er.id AND cracking_e.phase_type = 'cracking'
LEFT JOIN public.experiment_phase_executions shelling_e
ON shelling_e.repetition_id = er.id AND shelling_e.phase_type = 'shelling'
LEFT JOIN public.machine_types mt ON cracking_e.machine_type_id = mt.id
WHERE e.id = p_experiment_id
GROUP BY e.id, e.experiment_number, ep.name;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Grant execute permission
GRANT EXECUTE ON FUNCTION public.get_experiment_with_reps_and_phases(UUID) TO authenticated;
-- Update the existing experiments_with_phases view to use unified table
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.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,
er.id as first_repetition_id,
er.repetition_number as first_repetition_number,
soaking_e.id as soaking_id,
soaking_e.scheduled_start_time as soaking_scheduled_start,
soaking_e.actual_start_time as soaking_actual_start,
soaking_e.soaking_duration_minutes,
soaking_e.scheduled_end_time as soaking_scheduled_end,
soaking_e.actual_end_time as soaking_actual_end,
airdrying_e.id as airdrying_id,
airdrying_e.scheduled_start_time as airdrying_scheduled_start,
airdrying_e.actual_start_time as airdrying_actual_start,
airdrying_e.duration_minutes as airdrying_duration,
airdrying_e.scheduled_end_time as airdrying_scheduled_end,
airdrying_e.actual_end_time as airdrying_actual_end,
cracking_e.id as cracking_id,
cracking_e.scheduled_start_time as cracking_scheduled_start,
cracking_e.actual_start_time as cracking_actual_start,
cracking_e.actual_end_time as cracking_actual_end,
mt.name as machine_type_name,
shelling_e.id as shelling_id,
shelling_e.scheduled_start_time as shelling_scheduled_start,
shelling_e.actual_start_time as shelling_actual_start,
shelling_e.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 LATERAL (
SELECT id, repetition_number
FROM public.experiment_repetitions
WHERE experiment_id = e.id
ORDER BY repetition_number
LIMIT 1
) er ON true
LEFT JOIN public.experiment_phase_executions soaking_e
ON soaking_e.repetition_id = er.id AND soaking_e.phase_type = 'soaking'
LEFT JOIN public.experiment_phase_executions airdrying_e
ON airdrying_e.repetition_id = er.id AND airdrying_e.phase_type = 'airdrying'
LEFT JOIN public.experiment_phase_executions cracking_e
ON cracking_e.repetition_id = er.id AND cracking_e.phase_type = 'cracking'
LEFT JOIN public.experiment_phase_executions shelling_e
ON shelling_e.repetition_id = er.id AND shelling_e.phase_type = 'shelling'
LEFT JOIN public.machine_types mt ON cracking_e.machine_type_id = mt.id;
-- Update repetitions_with_phases view to use unified table
CREATE OR REPLACE VIEW public.repetitions_with_phases AS
SELECT
er.id,
er.experiment_id,
er.repetition_number,
er.status,
er.created_at,
er.updated_at,
er.created_by,
e.experiment_number,
e.phase_id,
e.weight_per_repetition_lbs,
ep.name as phase_name,
ep.has_soaking,
ep.has_airdrying,
ep.has_cracking,
ep.has_shelling,
soaking_e.scheduled_start_time as soaking_scheduled_start,
soaking_e.actual_start_time as soaking_actual_start,
soaking_e.soaking_duration_minutes,
soaking_e.scheduled_end_time as soaking_scheduled_end,
soaking_e.actual_end_time as soaking_actual_end,
airdrying_e.scheduled_start_time as airdrying_scheduled_start,
airdrying_e.actual_start_time as airdrying_actual_start,
airdrying_e.duration_minutes as airdrying_duration,
airdrying_e.scheduled_end_time as airdrying_scheduled_end,
airdrying_e.actual_end_time as airdrying_actual_end,
cracking_e.scheduled_start_time as cracking_scheduled_start,
cracking_e.actual_start_time as cracking_actual_start,
cracking_e.actual_end_time as cracking_actual_end,
mt.name as machine_type_name,
shelling_e.scheduled_start_time as shelling_scheduled_start,
shelling_e.actual_start_time as shelling_actual_start,
shelling_e.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.experiment_phase_executions soaking_e
ON er.id = soaking_e.repetition_id AND soaking_e.phase_type = 'soaking'
LEFT JOIN public.experiment_phase_executions airdrying_e
ON er.id = airdrying_e.repetition_id AND airdrying_e.phase_type = 'airdrying'
LEFT JOIN public.experiment_phase_executions cracking_e
ON er.id = cracking_e.repetition_id AND cracking_e.phase_type = 'cracking'
LEFT JOIN public.experiment_phase_executions shelling_e
ON er.id = shelling_e.repetition_id AND shelling_e.phase_type = 'shelling'
LEFT JOIN public.machine_types mt ON cracking_e.machine_type_id = mt.id;