feat: Implement Vision System API Client with comprehensive endpoints and utility functions

- Added VisionApiClient class to interact with the vision system API.
- Defined interfaces for system status, machine status, camera status, recordings, and storage stats.
- Implemented methods for health checks, system status retrieval, camera control, and storage management.
- Introduced utility functions for formatting bytes, durations, and uptime.

test: Create manual verification script for Vision API functionality

- Added a test script to verify utility functions and API endpoints.
- Included tests for health check, system status, cameras, machines, and storage stats.

feat: Create experiment repetitions system migration

- Added experiment_repetitions table to manage experiment repetitions with scheduling.
- Implemented triggers and functions for validation and timestamp management.
- Established row-level security policies for user access control.

feat: Introduce phase-specific draft management system migration

- Created experiment_phase_drafts and experiment_phase_data tables for managing phase-specific drafts and measurements.
- Added pecan_diameter_measurements table for individual diameter measurements.
- Implemented row-level security policies for user access control.

fix: Adjust draft constraints to allow multiple drafts while preventing multiple submitted drafts

- Modified constraints on experiment_phase_drafts to allow multiple drafts in 'draft' or 'withdrawn' status.
- Ensured only one 'submitted' draft per user per phase per repetition.
This commit is contained in:
Alireza Vaezi
2025-07-28 16:30:56 -04:00
parent 0d0c67d5c1
commit d598281164
27 changed files with 4219 additions and 683 deletions

View File

@@ -1,263 +0,0 @@
-- Experiment Data Entry System Migration
-- Creates tables for collaborative data entry with draft functionality and phase-based organization
-- Create experiment_data_entries table for main data entry records
CREATE TABLE IF NOT EXISTS public.experiment_data_entries (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES public.user_profiles(id),
status TEXT NOT NULL DEFAULT 'draft' CHECK (status IN ('draft', 'submitted')),
entry_name TEXT, -- Optional name for the entry (e.g., "Morning Run", "Batch A")
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
submitted_at TIMESTAMP WITH TIME ZONE, -- When status changed to 'submitted'
-- Constraint: Only one submitted entry per user per experiment
CONSTRAINT unique_submitted_entry_per_user_experiment
EXCLUDE (experiment_id WITH =, user_id WITH =)
WHERE (status = 'submitted')
);
-- Create experiment_phase_data table for phase-specific measurements
CREATE TABLE IF NOT EXISTS public.experiment_phase_data (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
data_entry_id UUID NOT NULL REFERENCES public.experiment_data_entries(id) ON DELETE CASCADE,
phase_name TEXT NOT NULL CHECK (phase_name IN ('pre-soaking', 'air-drying', 'cracking', 'shelling')),
-- Pre-soaking phase data
batch_initial_weight_lbs FLOAT CHECK (batch_initial_weight_lbs >= 0),
initial_shell_moisture_pct FLOAT CHECK (initial_shell_moisture_pct >= 0 AND initial_shell_moisture_pct <= 100),
initial_kernel_moisture_pct FLOAT CHECK (initial_kernel_moisture_pct >= 0 AND initial_kernel_moisture_pct <= 100),
soaking_start_time TIMESTAMP WITH TIME ZONE,
-- Air-drying phase data
airdrying_start_time TIMESTAMP WITH TIME ZONE,
post_soak_weight_lbs FLOAT CHECK (post_soak_weight_lbs >= 0),
post_soak_kernel_moisture_pct FLOAT CHECK (post_soak_kernel_moisture_pct >= 0 AND post_soak_kernel_moisture_pct <= 100),
post_soak_shell_moisture_pct FLOAT CHECK (post_soak_shell_moisture_pct >= 0 AND post_soak_shell_moisture_pct <= 100),
avg_pecan_diameter_in FLOAT CHECK (avg_pecan_diameter_in >= 0),
-- Cracking phase data
cracking_start_time TIMESTAMP WITH TIME ZONE,
-- Shelling phase data
shelling_start_time TIMESTAMP WITH TIME ZONE,
bin_1_weight_lbs FLOAT CHECK (bin_1_weight_lbs >= 0),
bin_2_weight_lbs FLOAT CHECK (bin_2_weight_lbs >= 0),
bin_3_weight_lbs FLOAT CHECK (bin_3_weight_lbs >= 0),
discharge_bin_weight_lbs FLOAT CHECK (discharge_bin_weight_lbs >= 0),
bin_1_full_yield_oz FLOAT CHECK (bin_1_full_yield_oz >= 0),
bin_2_full_yield_oz FLOAT CHECK (bin_2_full_yield_oz >= 0),
bin_3_full_yield_oz FLOAT CHECK (bin_3_full_yield_oz >= 0),
bin_1_half_yield_oz FLOAT CHECK (bin_1_half_yield_oz >= 0),
bin_2_half_yield_oz FLOAT CHECK (bin_2_half_yield_oz >= 0),
bin_3_half_yield_oz FLOAT CHECK (bin_3_half_yield_oz >= 0),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- Constraint: One record per phase per data entry
CONSTRAINT unique_phase_per_data_entry UNIQUE (data_entry_id, phase_name)
);
-- Create pecan_diameter_measurements table for individual diameter measurements
CREATE TABLE IF NOT EXISTS public.pecan_diameter_measurements (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
phase_data_id UUID NOT NULL REFERENCES public.experiment_phase_data(id) ON DELETE CASCADE,
measurement_number INTEGER NOT NULL CHECK (measurement_number >= 1 AND measurement_number <= 10),
diameter_in FLOAT NOT NULL CHECK (diameter_in >= 0),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- Constraint: Unique measurement number per phase data
CONSTRAINT unique_measurement_per_phase UNIQUE (phase_data_id, measurement_number)
);
-- Create indexes for better performance
CREATE INDEX IF NOT EXISTS idx_experiment_data_entries_experiment_id ON public.experiment_data_entries(experiment_id);
CREATE INDEX IF NOT EXISTS idx_experiment_data_entries_user_id ON public.experiment_data_entries(user_id);
CREATE INDEX IF NOT EXISTS idx_experiment_data_entries_status ON public.experiment_data_entries(status);
CREATE INDEX IF NOT EXISTS idx_experiment_data_entries_created_at ON public.experiment_data_entries(created_at);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_data_entry_id ON public.experiment_phase_data(data_entry_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_data_phase_name ON public.experiment_phase_data(phase_name);
CREATE INDEX IF NOT EXISTS idx_pecan_diameter_measurements_phase_data_id ON public.pecan_diameter_measurements(phase_data_id);
-- Create triggers for updated_at
CREATE TRIGGER set_updated_at_experiment_data_entries
BEFORE UPDATE ON public.experiment_data_entries
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
CREATE TRIGGER set_updated_at_experiment_phase_data
BEFORE UPDATE ON public.experiment_phase_data
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- Create trigger to set submitted_at timestamp
CREATE OR REPLACE FUNCTION public.handle_data_entry_submission()
RETURNS TRIGGER AS $$
BEGIN
-- Set submitted_at when status changes to 'submitted'
IF NEW.status = 'submitted' AND OLD.status != 'submitted' THEN
NEW.submitted_at = NOW();
END IF;
-- Clear submitted_at when status changes from 'submitted' to 'draft'
IF NEW.status = 'draft' AND OLD.status = 'submitted' THEN
NEW.submitted_at = NULL;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER set_submitted_at_experiment_data_entries
BEFORE UPDATE ON public.experiment_data_entries
FOR EACH ROW
EXECUTE FUNCTION public.handle_data_entry_submission();
-- Enable RLS on all tables
ALTER TABLE public.experiment_data_entries ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.experiment_phase_data ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.pecan_diameter_measurements ENABLE ROW LEVEL SECURITY;
-- RLS Policies for experiment_data_entries table
-- Policy: All authenticated users can view all data entries
CREATE POLICY "experiment_data_entries_select_policy" ON public.experiment_data_entries
FOR SELECT
TO authenticated
USING (true);
-- Policy: All authenticated users can insert data entries
CREATE POLICY "experiment_data_entries_insert_policy" ON public.experiment_data_entries
FOR INSERT
TO authenticated
WITH CHECK (user_id = auth.uid());
-- Policy: Users can only update their own data entries
CREATE POLICY "experiment_data_entries_update_policy" ON public.experiment_data_entries
FOR UPDATE
TO authenticated
USING (user_id = auth.uid())
WITH CHECK (user_id = auth.uid());
-- Policy: Users can only delete their own draft entries
CREATE POLICY "experiment_data_entries_delete_policy" ON public.experiment_data_entries
FOR DELETE
TO authenticated
USING (user_id = auth.uid() AND status = 'draft');
-- RLS Policies for experiment_phase_data table
-- Policy: All authenticated users can view phase data
CREATE POLICY "experiment_phase_data_select_policy" ON public.experiment_phase_data
FOR SELECT
TO authenticated
USING (true);
-- Policy: Users can insert phase data for their own data entries
CREATE POLICY "experiment_phase_data_insert_policy" ON public.experiment_phase_data
FOR INSERT
TO authenticated
WITH CHECK (
EXISTS (
SELECT 1 FROM public.experiment_data_entries ede
WHERE ede.id = data_entry_id AND ede.user_id = auth.uid()
)
);
-- Policy: Users can update phase data for their own data entries
CREATE POLICY "experiment_phase_data_update_policy" ON public.experiment_phase_data
FOR UPDATE
TO authenticated
USING (
EXISTS (
SELECT 1 FROM public.experiment_data_entries ede
WHERE ede.id = data_entry_id AND ede.user_id = auth.uid()
)
)
WITH CHECK (
EXISTS (
SELECT 1 FROM public.experiment_data_entries ede
WHERE ede.id = data_entry_id AND ede.user_id = auth.uid()
)
);
-- Policy: Users can delete phase data for their own draft entries
CREATE POLICY "experiment_phase_data_delete_policy" ON public.experiment_phase_data
FOR DELETE
TO authenticated
USING (
EXISTS (
SELECT 1 FROM public.experiment_data_entries ede
WHERE ede.id = data_entry_id AND ede.user_id = auth.uid() AND ede.status = 'draft'
)
);
-- RLS Policies for pecan_diameter_measurements table
-- Policy: All authenticated users can view diameter measurements
CREATE POLICY "pecan_diameter_measurements_select_policy" ON public.pecan_diameter_measurements
FOR SELECT
TO authenticated
USING (true);
-- Policy: Users can insert measurements for their own phase data
CREATE POLICY "pecan_diameter_measurements_insert_policy" ON public.pecan_diameter_measurements
FOR INSERT
TO authenticated
WITH CHECK (
EXISTS (
SELECT 1 FROM public.experiment_phase_data epd
JOIN public.experiment_data_entries ede ON epd.data_entry_id = ede.id
WHERE epd.id = phase_data_id AND ede.user_id = auth.uid()
)
);
-- Policy: Users can update measurements for their own phase data
CREATE POLICY "pecan_diameter_measurements_update_policy" ON public.pecan_diameter_measurements
FOR UPDATE
TO authenticated
USING (
EXISTS (
SELECT 1 FROM public.experiment_phase_data epd
JOIN public.experiment_data_entries ede ON epd.data_entry_id = ede.id
WHERE epd.id = phase_data_id AND ede.user_id = auth.uid()
)
)
WITH CHECK (
EXISTS (
SELECT 1 FROM public.experiment_phase_data epd
JOIN public.experiment_data_entries ede ON epd.data_entry_id = ede.id
WHERE epd.id = phase_data_id AND ede.user_id = auth.uid()
)
);
-- Policy: Users can delete measurements for their own draft entries
CREATE POLICY "pecan_diameter_measurements_delete_policy" ON public.pecan_diameter_measurements
FOR DELETE
TO authenticated
USING (
EXISTS (
SELECT 1 FROM public.experiment_phase_data epd
JOIN public.experiment_data_entries ede ON epd.data_entry_id = ede.id
WHERE epd.id = phase_data_id AND ede.user_id = auth.uid() AND ede.status = 'draft'
)
);
-- Add comments for documentation
COMMENT ON TABLE public.experiment_data_entries IS 'Main data entry records for experiments with draft/submitted status tracking';
COMMENT ON TABLE public.experiment_phase_data IS 'Phase-specific measurement data for experiments';
COMMENT ON TABLE public.pecan_diameter_measurements IS 'Individual pecan diameter measurements (up to 10 per phase)';
COMMENT ON COLUMN public.experiment_data_entries.status IS 'Entry status: draft (editable) or submitted (final)';
COMMENT ON COLUMN public.experiment_data_entries.entry_name IS 'Optional descriptive name for the data entry';
COMMENT ON COLUMN public.experiment_data_entries.submitted_at IS 'Timestamp when entry was submitted (status changed to submitted)';
COMMENT ON COLUMN public.experiment_phase_data.phase_name IS 'Experiment phase: pre-soaking, air-drying, cracking, or shelling';
COMMENT ON COLUMN public.experiment_phase_data.avg_pecan_diameter_in IS 'Average of up to 10 individual diameter measurements';
COMMENT ON COLUMN public.pecan_diameter_measurements.measurement_number IS 'Measurement sequence number (1-10)';
COMMENT ON COLUMN public.pecan_diameter_measurements.diameter_in IS 'Individual pecan diameter measurement in inches';

View File

@@ -0,0 +1,135 @@
-- Experiment Repetitions System Migration
-- Transforms experiments into blueprints/templates with schedulable repetitions
-- This migration creates the repetitions table and removes scheduling from experiments
-- Note: Data clearing removed since this runs during fresh database setup
-- 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),
scheduled_date TIMESTAMP WITH TIME ZONE,
schedule_status TEXT NOT NULL DEFAULT 'pending schedule'
CHECK (schedule_status IN ('pending schedule', 'scheduled', 'canceled', 'aborted')),
completion_status 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 unique repetition numbers per experiment
CONSTRAINT unique_repetition_per_experiment UNIQUE (experiment_id, repetition_number)
);
-- Create indexes for better 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_schedule_status ON public.experiment_repetitions(schedule_status);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_completion_status ON public.experiment_repetitions(completion_status);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_scheduled_date ON public.experiment_repetitions(scheduled_date);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_created_by ON public.experiment_repetitions(created_by);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_created_at ON public.experiment_repetitions(created_at);
-- Remove scheduling fields from experiments table since experiments are now blueprints
ALTER TABLE public.experiments DROP COLUMN IF EXISTS scheduled_date;
ALTER TABLE public.experiments DROP COLUMN IF EXISTS schedule_status;
-- Drop related indexes that are no longer needed
DROP INDEX IF EXISTS idx_experiments_schedule_status;
DROP INDEX IF EXISTS idx_experiments_scheduled_date;
-- Note: experiment_data_entries table is replaced by experiment_phase_drafts in the new system
-- Function to validate repetition number doesn't exceed experiment's reps_required
CREATE OR REPLACE FUNCTION validate_repetition_number()
RETURNS TRIGGER AS $$
DECLARE
max_reps INTEGER;
BEGIN
-- Get the reps_required for this experiment
SELECT reps_required INTO max_reps
FROM public.experiments
WHERE id = NEW.experiment_id;
-- Check if repetition number exceeds the limit
IF NEW.repetition_number > max_reps THEN
RAISE EXCEPTION 'Repetition number % exceeds maximum allowed repetitions % for experiment',
NEW.repetition_number, max_reps;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Update the trigger function for experiment_repetitions
CREATE OR REPLACE FUNCTION update_experiment_repetitions_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Create trigger to validate repetition number
CREATE TRIGGER trigger_validate_repetition_number
BEFORE INSERT OR UPDATE ON public.experiment_repetitions
FOR EACH ROW
EXECUTE FUNCTION validate_repetition_number();
-- Create trigger for updated_at on experiment_repetitions
CREATE TRIGGER trigger_experiment_repetitions_updated_at
BEFORE UPDATE ON public.experiment_repetitions
FOR EACH ROW
EXECUTE FUNCTION update_experiment_repetitions_updated_at();
-- Enable RLS on experiment_repetitions table
ALTER TABLE public.experiment_repetitions ENABLE ROW LEVEL SECURITY;
-- Create RLS policies for experiment_repetitions
-- Users can view repetitions for experiments they have access to
CREATE POLICY "Users can view experiment repetitions" ON public.experiment_repetitions
FOR SELECT USING (
experiment_id IN (
SELECT id FROM public.experiments
WHERE created_by = auth.uid()
)
OR public.is_admin()
);
-- Users can insert repetitions for experiments they created or if they're admin
CREATE POLICY "Users can create experiment repetitions" ON public.experiment_repetitions
FOR INSERT WITH CHECK (
experiment_id IN (
SELECT id FROM public.experiments
WHERE created_by = auth.uid()
)
OR public.is_admin()
);
-- Users can update repetitions for experiments they created or if they're admin
CREATE POLICY "Users can update experiment repetitions" ON public.experiment_repetitions
FOR UPDATE USING (
experiment_id IN (
SELECT id FROM public.experiments
WHERE created_by = auth.uid()
)
OR public.is_admin()
);
-- Users can delete repetitions for experiments they created or if they're admin
CREATE POLICY "Users can delete experiment repetitions" ON public.experiment_repetitions
FOR DELETE USING (
experiment_id IN (
SELECT id FROM public.experiments
WHERE created_by = auth.uid()
)
OR public.is_admin()
);
-- Add comments for documentation
COMMENT ON TABLE public.experiment_repetitions IS 'Individual repetitions of experiment blueprints that can be scheduled and executed';
COMMENT ON COLUMN public.experiment_repetitions.experiment_id IS 'Reference to the experiment blueprint';
COMMENT ON COLUMN public.experiment_repetitions.repetition_number IS 'Sequential number of this repetition (1, 2, 3, etc.)';
COMMENT ON COLUMN public.experiment_repetitions.scheduled_date IS 'Date and time when this repetition is scheduled to run';
COMMENT ON COLUMN public.experiment_repetitions.schedule_status IS 'Current scheduling status of this repetition';
COMMENT ON COLUMN public.experiment_repetitions.completion_status IS 'Whether this repetition has been completed';
-- Note: experiment_data_entries table is replaced by experiment_phase_drafts in the new system

View File

@@ -0,0 +1,332 @@
-- Phase-Specific Draft System Migration
-- Creates tables for the new phase-specific draft management system
-- Create experiment_phase_drafts table for phase-specific draft management
CREATE TABLE IF NOT EXISTS public.experiment_phase_drafts (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE,
repetition_id UUID NOT NULL REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES public.user_profiles(id),
phase_name TEXT NOT NULL CHECK (phase_name IN ('pre-soaking', 'air-drying', 'cracking', 'shelling')),
status TEXT NOT NULL DEFAULT 'draft' CHECK (status IN ('draft', 'submitted', 'withdrawn')),
draft_name TEXT, -- Optional name for the draft (e.g., "Morning Run", "Batch A")
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
submitted_at TIMESTAMP WITH TIME ZONE, -- When status changed to 'submitted'
withdrawn_at TIMESTAMP WITH TIME ZONE -- When status changed to 'withdrawn'
);
-- Add repetition locking support
ALTER TABLE public.experiment_repetitions
ADD COLUMN IF NOT EXISTS is_locked BOOLEAN NOT NULL DEFAULT false,
ADD COLUMN IF NOT EXISTS locked_at TIMESTAMP WITH TIME ZONE,
ADD COLUMN IF NOT EXISTS locked_by UUID REFERENCES public.user_profiles(id);
-- Create experiment_phase_data table for phase-specific measurements
CREATE TABLE IF NOT EXISTS public.experiment_phase_data (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
phase_draft_id UUID NOT NULL REFERENCES public.experiment_phase_drafts(id) ON DELETE CASCADE,
phase_name TEXT NOT NULL CHECK (phase_name IN ('pre-soaking', 'air-drying', 'cracking', 'shelling')),
-- Pre-soaking phase data
batch_initial_weight_lbs FLOAT CHECK (batch_initial_weight_lbs >= 0),
initial_shell_moisture_pct FLOAT CHECK (initial_shell_moisture_pct >= 0 AND initial_shell_moisture_pct <= 100),
initial_kernel_moisture_pct FLOAT CHECK (initial_kernel_moisture_pct >= 0 AND initial_kernel_moisture_pct <= 100),
soaking_start_time TIMESTAMP WITH TIME ZONE,
-- Air-drying phase data
airdrying_start_time TIMESTAMP WITH TIME ZONE,
post_soak_weight_lbs FLOAT CHECK (post_soak_weight_lbs >= 0),
post_soak_kernel_moisture_pct FLOAT CHECK (post_soak_kernel_moisture_pct >= 0 AND post_soak_kernel_moisture_pct <= 100),
post_soak_shell_moisture_pct FLOAT CHECK (post_soak_shell_moisture_pct >= 0 AND post_soak_shell_moisture_pct <= 100),
avg_pecan_diameter_in FLOAT CHECK (avg_pecan_diameter_in >= 0),
-- Cracking phase data
cracking_start_time TIMESTAMP WITH TIME ZONE,
-- Shelling phase data
shelling_start_time TIMESTAMP WITH TIME ZONE,
bin_1_weight_lbs FLOAT CHECK (bin_1_weight_lbs >= 0),
bin_2_weight_lbs FLOAT CHECK (bin_2_weight_lbs >= 0),
bin_3_weight_lbs FLOAT CHECK (bin_3_weight_lbs >= 0),
discharge_bin_weight_lbs FLOAT CHECK (discharge_bin_weight_lbs >= 0),
bin_1_full_yield_oz FLOAT CHECK (bin_1_full_yield_oz >= 0),
bin_2_full_yield_oz FLOAT CHECK (bin_2_full_yield_oz >= 0),
bin_3_full_yield_oz FLOAT CHECK (bin_3_full_yield_oz >= 0),
bin_1_half_yield_oz FLOAT CHECK (bin_1_half_yield_oz >= 0),
bin_2_half_yield_oz FLOAT CHECK (bin_2_half_yield_oz >= 0),
bin_3_half_yield_oz FLOAT CHECK (bin_3_half_yield_oz >= 0),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- Constraint: One record per phase draft
CONSTRAINT unique_phase_per_draft UNIQUE (phase_draft_id, phase_name)
);
-- Create pecan_diameter_measurements table for individual diameter measurements
CREATE TABLE IF NOT EXISTS public.pecan_diameter_measurements (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
phase_data_id UUID NOT NULL REFERENCES public.experiment_phase_data(id) ON DELETE CASCADE,
measurement_number INTEGER NOT NULL CHECK (measurement_number >= 1 AND measurement_number <= 10),
diameter_in FLOAT NOT NULL CHECK (diameter_in >= 0),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
-- Constraint: Unique measurement number per phase data
CONSTRAINT unique_measurement_per_phase UNIQUE (phase_data_id, measurement_number)
);
-- Create indexes for better performance
CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_experiment_id ON public.experiment_phase_drafts(experiment_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_repetition_id ON public.experiment_phase_drafts(repetition_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_user_id ON public.experiment_phase_drafts(user_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_phase_name ON public.experiment_phase_drafts(phase_name);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_status ON public.experiment_phase_drafts(status);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_is_locked ON public.experiment_repetitions(is_locked);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_data_draft_id ON public.experiment_phase_data(phase_draft_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_data_phase_name ON public.experiment_phase_data(phase_name);
CREATE INDEX IF NOT EXISTS idx_pecan_diameter_measurements_phase_data_id ON public.pecan_diameter_measurements(phase_data_id);
-- Create triggers for updated_at
CREATE TRIGGER set_updated_at_experiment_phase_drafts
BEFORE UPDATE ON public.experiment_phase_drafts
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
CREATE TRIGGER set_updated_at_experiment_phase_data
BEFORE UPDATE ON public.experiment_phase_data
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- Create trigger to set submitted_at and withdrawn_at timestamps for phase drafts
CREATE OR REPLACE FUNCTION public.handle_phase_draft_status_change()
RETURNS TRIGGER AS $$
BEGIN
-- Set submitted_at when status changes to 'submitted'
IF NEW.status = 'submitted' AND OLD.status != 'submitted' THEN
NEW.submitted_at = NOW();
NEW.withdrawn_at = NULL;
END IF;
-- Set withdrawn_at when status changes to 'withdrawn'
IF NEW.status = 'withdrawn' AND OLD.status = 'submitted' THEN
NEW.withdrawn_at = NOW();
END IF;
-- Clear timestamps when status changes back to 'draft'
IF NEW.status = 'draft' AND OLD.status IN ('submitted', 'withdrawn') THEN
NEW.submitted_at = NULL;
NEW.withdrawn_at = NULL;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER set_timestamps_experiment_phase_drafts
BEFORE UPDATE ON public.experiment_phase_drafts
FOR EACH ROW
EXECUTE FUNCTION public.handle_phase_draft_status_change();
-- Enable RLS on all tables
ALTER TABLE public.experiment_phase_drafts ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.experiment_phase_data ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.pecan_diameter_measurements ENABLE ROW LEVEL SECURITY;
-- RLS Policies for experiment_phase_drafts table
-- Policy: All authenticated users can view all phase drafts
CREATE POLICY "experiment_phase_drafts_select_policy" ON public.experiment_phase_drafts
FOR SELECT
TO authenticated
USING (true);
-- Policy: All authenticated users can insert phase drafts
CREATE POLICY "experiment_phase_drafts_insert_policy" ON public.experiment_phase_drafts
FOR INSERT
TO authenticated
WITH CHECK (user_id = auth.uid());
-- Policy: Users can update their own phase drafts if repetition is not locked, admins can update any
CREATE POLICY "experiment_phase_drafts_update_policy" ON public.experiment_phase_drafts
FOR UPDATE
TO authenticated
USING (
(user_id = auth.uid() AND NOT EXISTS (
SELECT 1 FROM public.experiment_repetitions
WHERE id = repetition_id AND is_locked = true
)) OR public.is_admin()
)
WITH CHECK (
(user_id = auth.uid() AND NOT EXISTS (
SELECT 1 FROM public.experiment_repetitions
WHERE id = repetition_id AND is_locked = true
)) OR public.is_admin()
);
-- Policy: Users can delete their own draft phase drafts if repetition is not locked, admins can delete any
CREATE POLICY "experiment_phase_drafts_delete_policy" ON public.experiment_phase_drafts
FOR DELETE
TO authenticated
USING (
(user_id = auth.uid() AND status = 'draft' AND NOT EXISTS (
SELECT 1 FROM public.experiment_repetitions
WHERE id = repetition_id AND is_locked = true
)) OR public.is_admin()
);
-- RLS Policies for experiment_phase_data table
-- Policy: All authenticated users can view phase data
CREATE POLICY "experiment_phase_data_select_policy" ON public.experiment_phase_data
FOR SELECT
TO authenticated
USING (true);
-- Policy: Users can insert phase data for their own phase drafts
CREATE POLICY "experiment_phase_data_insert_policy" ON public.experiment_phase_data
FOR INSERT
TO authenticated
WITH CHECK (
EXISTS (
SELECT 1 FROM public.experiment_phase_drafts epd
WHERE epd.id = phase_draft_id AND epd.user_id = auth.uid()
)
);
-- Policy: Users can update phase data for their own phase drafts
CREATE POLICY "experiment_phase_data_update_policy" ON public.experiment_phase_data
FOR UPDATE
TO authenticated
USING (
EXISTS (
SELECT 1 FROM public.experiment_phase_drafts epd
WHERE epd.id = phase_draft_id AND epd.user_id = auth.uid()
)
)
WITH CHECK (
EXISTS (
SELECT 1 FROM public.experiment_phase_drafts epd
WHERE epd.id = phase_draft_id AND epd.user_id = auth.uid()
)
);
-- Policy: Users can delete phase data for their own draft phase drafts
CREATE POLICY "experiment_phase_data_delete_policy" ON public.experiment_phase_data
FOR DELETE
TO authenticated
USING (
EXISTS (
SELECT 1 FROM public.experiment_phase_drafts epd
WHERE epd.id = phase_draft_id AND epd.user_id = auth.uid() AND epd.status = 'draft'
)
);
-- RLS Policies for pecan_diameter_measurements table
-- Policy: All authenticated users can view diameter measurements
CREATE POLICY "pecan_diameter_measurements_select_policy" ON public.pecan_diameter_measurements
FOR SELECT
TO authenticated
USING (true);
-- Policy: Users can insert measurements for their own phase data
CREATE POLICY "pecan_diameter_measurements_insert_policy" ON public.pecan_diameter_measurements
FOR INSERT
TO authenticated
WITH CHECK (
EXISTS (
SELECT 1 FROM public.experiment_phase_data epd
JOIN public.experiment_phase_drafts epdr ON epd.phase_draft_id = epdr.id
WHERE epd.id = phase_data_id AND epdr.user_id = auth.uid()
)
);
-- Policy: Users can update measurements for their own phase data
CREATE POLICY "pecan_diameter_measurements_update_policy" ON public.pecan_diameter_measurements
FOR UPDATE
TO authenticated
USING (
EXISTS (
SELECT 1 FROM public.experiment_phase_data epd
JOIN public.experiment_phase_drafts epdr ON epd.phase_draft_id = epdr.id
WHERE epd.id = phase_data_id AND epdr.user_id = auth.uid()
)
)
WITH CHECK (
EXISTS (
SELECT 1 FROM public.experiment_phase_data epd
JOIN public.experiment_phase_drafts epdr ON epd.phase_draft_id = epdr.id
WHERE epd.id = phase_data_id AND epdr.user_id = auth.uid()
)
);
-- Policy: Users can delete measurements for their own draft phase drafts
CREATE POLICY "pecan_diameter_measurements_delete_policy" ON public.pecan_diameter_measurements
FOR DELETE
TO authenticated
USING (
EXISTS (
SELECT 1 FROM public.experiment_phase_data epd
JOIN public.experiment_phase_drafts epdr ON epd.phase_draft_id = epdr.id
WHERE epd.id = phase_data_id AND epdr.user_id = auth.uid() AND epdr.status = 'draft'
)
);
-- Add indexes for better performance
CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_repetition_id ON public.experiment_phase_drafts(repetition_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_user_id ON public.experiment_phase_drafts(user_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_phase_name ON public.experiment_phase_drafts(phase_name);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_status ON public.experiment_phase_drafts(status);
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_is_locked ON public.experiment_repetitions(is_locked);
-- Add comments for documentation
COMMENT ON TABLE public.experiment_phase_drafts IS 'Phase-specific draft records for experiment data entry with status tracking';
COMMENT ON TABLE public.experiment_phase_data IS 'Phase-specific measurement data for experiments';
COMMENT ON TABLE public.pecan_diameter_measurements IS 'Individual pecan diameter measurements (up to 10 per phase)';
COMMENT ON COLUMN public.experiment_phase_drafts.status IS 'Draft status: draft (editable), submitted (final), or withdrawn (reverted from submitted)';
COMMENT ON COLUMN public.experiment_phase_drafts.draft_name IS 'Optional descriptive name for the draft';
COMMENT ON COLUMN public.experiment_phase_drafts.submitted_at IS 'Timestamp when draft was submitted (status changed to submitted)';
COMMENT ON COLUMN public.experiment_phase_drafts.withdrawn_at IS 'Timestamp when draft was withdrawn (status changed from submitted to withdrawn)';
COMMENT ON COLUMN public.experiment_repetitions.is_locked IS 'Admin lock to prevent draft modifications and withdrawals';
COMMENT ON COLUMN public.experiment_repetitions.locked_at IS 'Timestamp when repetition was locked';
COMMENT ON COLUMN public.experiment_repetitions.locked_by IS 'User who locked the repetition';
COMMENT ON COLUMN public.experiment_phase_data.phase_name IS 'Experiment phase: pre-soaking, air-drying, cracking, or shelling';
COMMENT ON COLUMN public.experiment_phase_data.avg_pecan_diameter_in IS 'Average of up to 10 individual diameter measurements';
COMMENT ON COLUMN public.pecan_diameter_measurements.measurement_number IS 'Measurement sequence number (1-10)';
COMMENT ON COLUMN public.pecan_diameter_measurements.diameter_in IS 'Individual pecan diameter measurement in inches';
-- Add unique constraint to prevent multiple drafts of same phase by same user for same repetition
ALTER TABLE public.experiment_phase_drafts
ADD CONSTRAINT unique_user_phase_repetition_draft
UNIQUE (user_id, repetition_id, phase_name, status)
DEFERRABLE INITIALLY DEFERRED;
-- Add function to prevent withdrawal of submitted drafts when repetition is locked
CREATE OR REPLACE FUNCTION public.check_repetition_lock_before_withdrawal()
RETURNS TRIGGER AS $$
BEGIN
-- Check if repetition is locked when trying to withdraw a submitted draft
IF NEW.status = 'withdrawn' AND OLD.status = 'submitted' THEN
IF EXISTS (
SELECT 1 FROM public.experiment_repetitions
WHERE id = NEW.repetition_id AND is_locked = true
) THEN
RAISE EXCEPTION 'Cannot withdraw submitted draft: repetition is locked by admin';
END IF;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER check_lock_before_withdrawal
BEFORE UPDATE ON public.experiment_phase_drafts
FOR EACH ROW
EXECUTE FUNCTION public.check_repetition_lock_before_withdrawal();

View File

@@ -0,0 +1,17 @@
-- Fix Draft Constraints Migration
-- Allows multiple drafts per phase while preventing multiple submitted drafts
-- Drop the overly restrictive constraint
ALTER TABLE public.experiment_phase_drafts
DROP CONSTRAINT IF EXISTS unique_user_phase_repetition_draft;
-- Add a proper constraint that only prevents multiple submitted drafts
-- Users can have multiple drafts in 'draft' or 'withdrawn' status, but only one 'submitted' per phase
ALTER TABLE public.experiment_phase_drafts
ADD CONSTRAINT unique_submitted_draft_per_user_phase
EXCLUDE (user_id WITH =, repetition_id WITH =, phase_name WITH =)
WHERE (status = 'submitted');
-- Add comment explaining the constraint
COMMENT ON CONSTRAINT unique_submitted_draft_per_user_phase ON public.experiment_phase_drafts
IS 'Ensures only one submitted draft per user per phase per repetition, but allows multiple draft/withdrawn entries';

View File

@@ -1,6 +1,9 @@
-- Seed data for testing experiment scheduling functionality
-- Seed data for testing experiment repetitions functionality
-- Insert some sample experiments for testing
-- Insert experiments from phase_2_experimental_run_sheet.csv
-- These are experiment blueprints/templates with their parameters
-- Using run_number from CSV as experiment_number in database
-- Note: Some run_numbers are duplicated in the CSV, so we'll only insert unique ones
INSERT INTO public.experiments (
experiment_number,
reps_required,
@@ -10,51 +13,118 @@ INSERT INTO public.experiments (
throughput_rate_pecans_sec,
crush_amount_in,
entry_exit_height_diff_in,
schedule_status,
results_status,
created_by
) VALUES
(
1001,
5,
2.5,
30,
50.0,
2.5,
0.005,
1.2,
'pending schedule',
'valid',
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')
),
(
1002,
3,
1.0,
15,
45.0,
3.0,
0.003,
0.8,
'pending schedule',
'valid',
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')
),
(
1003,
4,
3.0,
45,
55.0,
2.0,
0.007,
1.5,
'scheduled',
'valid',
(SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')
);
) VALUES
-- Unique experiments based on run_number from CSV
(0, 3, 34, 19, 53, 28, 0.05, -0.09, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(1, 3, 24, 27, 34, 29, 0.03, 0.01, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(2, 3, 38, 10, 60, 28, 0.06, -0.1, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(3, 3, 11, 36, 42, 13, 0.07, -0.07, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(4, 3, 13, 41, 41, 38, 0.05, 0.03, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(5, 3, 30, 33, 30, 36, 0.05, -0.04, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(6, 3, 10, 22, 37, 30, 0.06, 0.02, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(7, 3, 15, 30, 35, 32, 0.05, -0.07, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(8, 3, 27, 12, 55, 24, 0.04, 0.04, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(9, 3, 32, 26, 47, 26, 0.07, 0.03, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(10, 3, 26, 60, 44, 12, 0.08, -0.1, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(11, 3, 24, 59, 42, 25, 0.07, -0.05, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(12, 3, 28, 59, 37, 23, 0.06, -0.08, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(13, 3, 21, 59, 41, 21, 0.06, -0.09, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(14, 3, 22, 59, 45, 17, 0.07, -0.08, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(15, 3, 16, 60, 30, 24, 0.07, 0.02, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(16, 3, 20, 59, 41, 14, 0.07, 0.04, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(17, 3, 34, 60, 34, 29, 0.07, -0.09, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(18, 3, 18, 49, 38, 35, 0.07, -0.08, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
(19, 3, 11, 25, 56, 34, 0.06, -0.09, 'valid', (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com'));
-- Update one experiment to have a scheduled date for testing
UPDATE public.experiments
SET scheduled_date = NOW() + INTERVAL '2 days'
WHERE experiment_number = 1003;
-- Create repetitions for all experiments based on CSV data
-- Each experiment has 3 repetitions as specified in the CSV
INSERT INTO public.experiment_repetitions (
experiment_id,
repetition_number,
schedule_status,
scheduled_date,
completion_status,
created_by
) VALUES
-- Experiment 0 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 0), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 0), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 0), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 1 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 1), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 1), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 1), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 2 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 2), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 2), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 2), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 3 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 3), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 3), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 3), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 4 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 4), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 4), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 4), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 5 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 5), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 5), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 5), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 6 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 6), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 6), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 6), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 7 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 7), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 7), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 7), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 8 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 8), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 8), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 8), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 9 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 9), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 9), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 9), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 10 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 10), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 10), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 10), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 11 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 11), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 11), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 11), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 12 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 12), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 12), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 12), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 13 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 13), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 13), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 13), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 14 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 14), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 14), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 14), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 15 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 15), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 15), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 15), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 16 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 16), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 16), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 16), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 17 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 17), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 17), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 17), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 18 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 18), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 18), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 18), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
-- Experiment 19 repetitions
((SELECT id FROM public.experiments WHERE experiment_number = 19), 1, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 19), 2, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
((SELECT id FROM public.experiments WHERE experiment_number = 19), 3, 'pending schedule', NULL, false, (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com'));