+ )
+}
diff --git a/management-dashboard-web-app/src/components/Scheduling.tsx b/management-dashboard-web-app/src/components/Scheduling.tsx
new file mode 100644
index 0000000..5226d75
--- /dev/null
+++ b/management-dashboard-web-app/src/components/Scheduling.tsx
@@ -0,0 +1,37 @@
+import type { User } from '../lib/supabase'
+
+interface SchedulingProps {
+ user: User
+}
+
+export function Scheduling({ user }: SchedulingProps) {
+ return (
+
+
+
+ Scheduling
+
+
+ This is the scheduling module of the dashboard. Here you can indicate your availability for upcoming experiment runs.
+
+
+
+
+
+
+
+
+
+ Scheduling Module
+
+
+ This module will allow you to manage your availability and schedule for upcoming experiment runs.
+ Features will include calendar integration, availability settings, and experiment scheduling.
+
{isExpanded || isHovered || isMobileOpen ? (
diff --git a/management-dashboard-web-app/src/lib/supabase.ts b/management-dashboard-web-app/src/lib/supabase.ts
index 84a7fc0..a7555de 100755
--- a/management-dashboard-web-app/src/lib/supabase.ts
+++ b/management-dashboard-web-app/src/lib/supabase.ts
@@ -32,6 +32,15 @@ export interface Role {
created_at: string
}
+export interface ExperimentPhase {
+ id: string
+ name: string
+ description?: string | null
+ created_at: string
+ updated_at: string
+ created_by: string
+}
+
export interface Experiment {
id: string
experiment_number: number
@@ -44,6 +53,7 @@ export interface Experiment {
entry_exit_height_diff_in: number
results_status: ResultsStatus
completion_status: boolean
+ phase_id?: string | null
created_at: string
updated_at: string
created_by: string
@@ -51,6 +61,16 @@ export interface Experiment {
+export interface CreateExperimentPhaseRequest {
+ name: string
+ description?: string
+}
+
+export interface UpdateExperimentPhaseRequest {
+ name?: string
+ description?: string
+}
+
export interface CreateExperimentRequest {
experiment_number: number
reps_required: number
@@ -62,6 +82,7 @@ export interface CreateExperimentRequest {
entry_exit_height_diff_in: number
results_status?: ResultsStatus
completion_status?: boolean
+ phase_id?: string
}
export interface UpdateExperimentRequest {
@@ -75,6 +96,7 @@ export interface UpdateExperimentRequest {
entry_exit_height_diff_in?: number
results_status?: ResultsStatus
completion_status?: boolean
+ phase_id?: string
}
export interface CreateRepetitionRequest {
@@ -378,6 +400,76 @@ export const userManagement = {
}
}
+// Experiment phase management utility functions
+export const experimentPhaseManagement = {
+ // Get all experiment phases
+ async getAllExperimentPhases(): Promise {
+ const { data, error } = await supabase
+ .from('experiment_phases')
+ .select('*')
+ .order('created_at', { ascending: false })
+
+ if (error) throw error
+ return data
+ },
+
+ // Get experiment phase by ID
+ async getExperimentPhaseById(id: string): Promise {
+ const { data, error } = await supabase
+ .from('experiment_phases')
+ .select('*')
+ .eq('id', id)
+ .single()
+
+ if (error) {
+ if (error.code === 'PGRST116') return null // Not found
+ throw error
+ }
+ return data
+ },
+
+ // Create a new experiment phase
+ async createExperimentPhase(phaseData: CreateExperimentPhaseRequest): Promise {
+ const { data: { user }, error: authError } = await supabase.auth.getUser()
+ if (authError || !user) throw new Error('User not authenticated')
+
+ const { data, error } = await supabase
+ .from('experiment_phases')
+ .insert({
+ ...phaseData,
+ created_by: user.id
+ })
+ .select()
+ .single()
+
+ if (error) throw error
+ return data
+ },
+
+ // Update an experiment phase
+ async updateExperimentPhase(id: string, updates: UpdateExperimentPhaseRequest): Promise {
+ const { data, error } = await supabase
+ .from('experiment_phases')
+ .update(updates)
+ .eq('id', id)
+ .select()
+ .single()
+
+ if (error) throw error
+ return data
+ },
+
+ // Delete an experiment phase
+ async deleteExperimentPhase(id: string): Promise {
+ const { error } = await supabase
+ .from('experiment_phases')
+ .delete()
+ .eq('id', id)
+
+ if (error) throw error
+ }
+}
+
// Experiment management utility functions
export const experimentManagement = {
// Get all experiments
@@ -391,6 +483,18 @@ export const experimentManagement = {
return data
},
+ // Get experiments by phase ID
+ async getExperimentsByPhaseId(phaseId: string): Promise {
+ const { data, error } = await supabase
+ .from('experiments')
+ .select('*')
+ .eq('phase_id', phaseId)
+ .order('created_at', { ascending: false })
+
+ if (error) throw error
+ return data
+ },
+
// Get experiment by ID
async getExperimentById(id: string): Promise {
const { data, error } = await supabase
diff --git a/management-dashboard-web-app/supabase/experiments_seed.sql b/management-dashboard-web-app/supabase/experiments_seed.sql
new file mode 100644
index 0000000..cdd6493
--- /dev/null
+++ b/management-dashboard-web-app/supabase/experiments_seed.sql
@@ -0,0 +1,196 @@
+-- Experiments Seed Data
+-- This file contains all 50 experiments for Phase 2 of JC Experiments
+
+-- =============================================
+-- INSERT ALL 50 EXPERIMENTS
+-- =============================================
+
+INSERT INTO public.experiments (
+ experiment_number,
+ reps_required,
+ soaking_duration_hr,
+ air_drying_time_min,
+ plate_contact_frequency_hz,
+ throughput_rate_pecans_sec,
+ crush_amount_in,
+ entry_exit_height_diff_in,
+ results_status,
+ completion_status,
+ phase_id,
+ created_by
+) VALUES
+-- Experiments 1-10
+(1, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(2, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(3, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(4, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(5, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(6, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(7, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(8, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(9, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(10, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+
+-- Experiments 11-20
+(11, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(12, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(13, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(14, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(15, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(16, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(17, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(18, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(19, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(20, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+
+-- Experiments 21-30
+(21, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(22, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(23, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(24, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(25, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(26, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(27, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(28, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(29, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(30, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+
+-- Experiments 31-40
+(31, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(32, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(33, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(34, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(35, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(36, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(37, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(38, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(39, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(40, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+
+-- Experiments 41-50
+(41, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(42, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(43, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(44, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(45, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(46, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(47, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(48, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(49, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(50, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com'))
+;
+
+-- =============================================
+-- CREATE SAMPLE EXPERIMENT REPETITIONS
+-- =============================================
+
+-- Create repetitions for first 5 experiments as examples
+INSERT INTO public.experiment_repetitions (experiment_id, repetition_number, created_by)
+SELECT
+ e.id,
+ rep_num,
+ e.created_by
+FROM public.experiments e
+CROSS JOIN generate_series(1, 3) AS rep_num
+WHERE e.experiment_number <= 5
+;
diff --git a/management-dashboard-web-app/supabase/migrations/20250101000001_complete_schema.sql b/management-dashboard-web-app/supabase/migrations/20250101000001_complete_schema.sql
new file mode 100644
index 0000000..b8e139f
--- /dev/null
+++ b/management-dashboard-web-app/supabase/migrations/20250101000001_complete_schema.sql
@@ -0,0 +1,785 @@
+-- Complete Database Schema for USDA Vision Pecan Experiments System
+-- This migration creates the entire database schema from scratch
+
+-- Enable necessary extensions
+CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
+
+-- =============================================
+-- 1. ROLES AND USER MANAGEMENT
+-- =============================================
+
+-- Create roles table
+CREATE TABLE IF NOT EXISTS public.roles (
+ id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
+ name TEXT UNIQUE NOT NULL CHECK (name IN ('admin', 'conductor', 'analyst', 'data recorder')),
+ description TEXT NOT NULL,
+ created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
+ updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
+);
+
+-- Create user_profiles table to extend auth.users
+CREATE TABLE IF NOT EXISTS public.user_profiles (
+ id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
+ email TEXT NOT NULL,
+ status TEXT DEFAULT 'active' CHECK (status IN ('active', 'disabled')),
+ created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
+ updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
+);
+
+-- Create user_roles junction table for many-to-many relationship
+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)
+);
+
+-- =============================================
+-- 2. EXPERIMENT PHASES
+-- =============================================
+
+-- Create experiment_phases table
+CREATE TABLE IF NOT EXISTS public.experiment_phases (
+ id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
+ name TEXT NOT NULL UNIQUE,
+ description TEXT,
+ 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)
+);
+
+-- =============================================
+-- 3. EXPERIMENTS
+-- =============================================
+
+-- Create experiments table
+CREATE TABLE IF NOT EXISTS public.experiments (
+ id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
+ experiment_number INTEGER UNIQUE NOT NULL,
+ reps_required INTEGER NOT NULL CHECK (reps_required > 0),
+ soaking_duration_hr FLOAT NOT NULL CHECK (soaking_duration_hr >= 0),
+ air_drying_time_min INTEGER NOT NULL CHECK (air_drying_time_min >= 0),
+ plate_contact_frequency_hz FLOAT NOT NULL CHECK (plate_contact_frequency_hz > 0),
+ throughput_rate_pecans_sec FLOAT NOT NULL CHECK (throughput_rate_pecans_sec > 0),
+ crush_amount_in FLOAT NOT NULL CHECK (crush_amount_in >= 0),
+ entry_exit_height_diff_in FLOAT NOT NULL,
+ results_status TEXT NOT NULL DEFAULT 'valid' CHECK (results_status IN ('valid', 'invalid')),
+ completion_status BOOLEAN NOT NULL DEFAULT false,
+ phase_id UUID REFERENCES public.experiment_phases(id) ON DELETE SET NULL,
+ created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
+ updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
+ created_by UUID NOT NULL REFERENCES public.user_profiles(id)
+);
+
+-- =============================================
+-- 4. EXPERIMENT REPETITIONS
+-- =============================================
+
+-- Create experiment_repetitions table
+CREATE TABLE IF NOT EXISTS public.experiment_repetitions (
+ id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
+ experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE,
+ repetition_number INTEGER NOT NULL CHECK (repetition_number > 0),
+ 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,
+ is_locked BOOLEAN NOT NULL DEFAULT false,
+ locked_at TIMESTAMP WITH TIME ZONE,
+ locked_by UUID REFERENCES public.user_profiles(id),
+ 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)
+);
+
+-- =============================================
+-- 5. DATA ENTRY 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,
+ created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
+ updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
+ submitted_at TIMESTAMP WITH TIME ZONE,
+ withdrawn_at TIMESTAMP WITH TIME ZONE
+);
+
+-- 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)
+);
+
+-- =============================================
+-- 6. INDEXES FOR PERFORMANCE
+-- =============================================
+
+-- User management indexes
+CREATE INDEX IF NOT EXISTS idx_user_profiles_email ON public.user_profiles(email);
+CREATE INDEX IF NOT EXISTS idx_user_profiles_status ON public.user_profiles(status);
+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);
+
+-- Experiment phases indexes
+CREATE INDEX IF NOT EXISTS idx_experiment_phases_name ON public.experiment_phases(name);
+CREATE INDEX IF NOT EXISTS idx_experiment_phases_created_by ON public.experiment_phases(created_by);
+
+-- Experiments indexes
+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_results_status ON public.experiments(results_status);
+CREATE INDEX IF NOT EXISTS idx_experiments_completion_status ON public.experiments(completion_status);
+CREATE INDEX IF NOT EXISTS idx_experiments_created_at ON public.experiments(created_at);
+CREATE INDEX IF NOT EXISTS idx_experiments_phase_id ON public.experiments(phase_id);
+
+-- Experiment repetitions indexes
+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);
+CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_is_locked ON public.experiment_repetitions(is_locked);
+
+-- Data entry system indexes
+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_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);
+
+-- =============================================
+-- 7. TRIGGERS AND FUNCTIONS
+-- =============================================
+
+-- Create updated_at trigger function
+CREATE OR REPLACE FUNCTION public.handle_updated_at()
+RETURNS TRIGGER AS $$
+BEGIN
+ NEW.updated_at = NOW();
+ RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+
+-- Create triggers for updated_at
+CREATE TRIGGER set_updated_at_roles
+ BEFORE UPDATE ON public.roles
+ FOR EACH ROW
+ EXECUTE FUNCTION public.handle_updated_at();
+
+CREATE TRIGGER set_updated_at_user_profiles
+ BEFORE UPDATE ON public.user_profiles
+ FOR EACH ROW
+ EXECUTE FUNCTION public.handle_updated_at();
+
+CREATE TRIGGER set_updated_at_experiment_phases
+ BEFORE UPDATE ON public.experiment_phases
+ FOR EACH ROW
+ EXECUTE FUNCTION public.handle_updated_at();
+
+CREATE TRIGGER set_updated_at_experiments
+ BEFORE UPDATE ON public.experiments
+ FOR EACH ROW
+ EXECUTE FUNCTION public.handle_updated_at();
+
+CREATE TRIGGER set_updated_at_experiment_repetitions
+ BEFORE UPDATE ON public.experiment_repetitions
+ FOR EACH ROW
+ EXECUTE FUNCTION public.handle_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();
+
+-- 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;
+
+-- 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();
+
+-- Function to handle phase draft status changes
+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();
+
+-- =============================================
+-- 8. HELPER FUNCTIONS
+-- =============================================
+
+-- 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;
+
+-- Function to generate secure temporary password
+CREATE OR REPLACE FUNCTION public.generate_temp_password()
+RETURNS TEXT AS $$
+DECLARE
+ chars TEXT := 'ABCDEFGHJKMNPQRSTUVWXYZabcdefghijkmnpqrstuvwxyz23456789';
+ result TEXT := '';
+ i INTEGER;
+BEGIN
+ FOR i IN 1..12 LOOP
+ result := result || substr(chars, floor(random() * length(chars) + 1)::integer, 1);
+ END LOOP;
+ RETURN result;
+END;
+$$ LANGUAGE plpgsql SECURITY DEFINER;
+
+-- Function to create user with roles (for admin use)
+CREATE OR REPLACE FUNCTION public.create_user_with_roles(
+ user_email TEXT,
+ role_names TEXT[],
+ temp_password TEXT DEFAULT NULL
+)
+RETURNS JSON AS $$
+DECLARE
+ new_user_id UUID;
+ role_record RECORD;
+ generated_password TEXT;
+ result JSON;
+ role_count INTEGER;
+BEGIN
+ -- Only admins can create users
+ IF NOT public.is_admin() THEN
+ RAISE EXCEPTION 'Only administrators can create users';
+ END IF;
+
+ -- Validate that at least one role is provided
+ IF array_length(role_names, 1) IS NULL OR array_length(role_names, 1) = 0 THEN
+ RAISE EXCEPTION 'At least one role must be assigned to the user';
+ END IF;
+
+ -- Validate that all provided roles exist
+ SELECT COUNT(*) INTO role_count
+ FROM public.roles
+ WHERE name = ANY(role_names);
+
+ IF role_count != array_length(role_names, 1) THEN
+ RAISE EXCEPTION 'One or more specified roles do not exist';
+ END IF;
+
+ -- Check if user already exists
+ IF EXISTS (SELECT 1 FROM auth.users WHERE email = user_email) THEN
+ RAISE EXCEPTION 'User with email % already exists', user_email;
+ END IF;
+
+ -- Generate password if not provided
+ IF temp_password IS NULL THEN
+ generated_password := public.generate_temp_password();
+ ELSE
+ generated_password := temp_password;
+ END IF;
+
+ -- Generate new user ID
+ new_user_id := uuid_generate_v4();
+
+ -- Insert into auth.users (simulating user creation)
+ 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,
+ crypt(generated_password, gen_salt('bf')),
+ NOW(),
+ NOW(),
+ NOW(),
+ '',
+ '',
+ '',
+ ''
+ );
+
+ -- Insert user profile
+ INSERT INTO public.user_profiles (id, email, status)
+ VALUES (new_user_id, user_email, 'active');
+
+ -- Assign roles through the user_roles junction table
+ FOR role_record IN
+ SELECT id FROM public.roles WHERE name = ANY(role_names)
+ LOOP
+ INSERT INTO public.user_roles (user_id, role_id, assigned_by)
+ VALUES (new_user_id, role_record.id, auth.uid());
+ END LOOP;
+
+ -- Return result
+ result := json_build_object(
+ 'user_id', new_user_id,
+ 'email', user_email,
+ 'temp_password', generated_password,
+ 'roles', role_names,
+ 'status', 'active'
+ );
+
+ RETURN result;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ -- Clean up any partial inserts
+ DELETE FROM public.user_roles WHERE user_id = new_user_id;
+ DELETE FROM public.user_profiles WHERE id = new_user_id;
+ DELETE FROM auth.users WHERE id = new_user_id;
+ RAISE;
+END;
+$$ LANGUAGE plpgsql SECURITY DEFINER;
+
+-- =============================================
+-- 9. ROW LEVEL SECURITY (RLS)
+-- =============================================
+
+-- Enable RLS on all tables
+ALTER TABLE public.roles ENABLE ROW LEVEL SECURITY;
+ALTER TABLE public.user_profiles ENABLE ROW LEVEL SECURITY;
+ALTER TABLE public.user_roles ENABLE ROW LEVEL SECURITY;
+ALTER TABLE public.experiment_phases ENABLE ROW LEVEL SECURITY;
+ALTER TABLE public.experiments ENABLE ROW LEVEL SECURITY;
+ALTER TABLE public.experiment_repetitions ENABLE ROW LEVEL SECURITY;
+ALTER TABLE public.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;
+
+-- Roles table policies
+CREATE POLICY "Anyone can read roles" ON public.roles
+ FOR SELECT USING (true);
+
+CREATE POLICY "Only admins can insert roles" ON public.roles
+ FOR INSERT WITH CHECK (public.is_admin());
+
+CREATE POLICY "Only admins can update roles" ON public.roles
+ FOR UPDATE USING (public.is_admin());
+
+CREATE POLICY "Only admins can delete roles" ON public.roles
+ FOR DELETE USING (public.is_admin());
+
+-- User profiles policies
+CREATE POLICY "Users can read own profile, admins can read all" ON public.user_profiles
+ FOR SELECT USING (
+ auth.uid() = id OR public.is_admin()
+ );
+
+CREATE POLICY "Only admins can insert user profiles" ON public.user_profiles
+ FOR INSERT WITH CHECK (public.is_admin());
+
+CREATE POLICY "Users can update own profile, admins can update any" ON public.user_profiles
+ FOR UPDATE USING (
+ auth.uid() = id OR public.is_admin()
+ );
+
+CREATE POLICY "Only admins can delete user profiles" ON public.user_profiles
+ FOR DELETE USING (public.is_admin());
+
+-- User roles policies
+CREATE POLICY "Users can read own roles, admins can read all" ON public.user_roles
+ FOR SELECT USING (
+ user_id = auth.uid() OR public.is_admin()
+ );
+
+CREATE POLICY "Only admins can assign roles" ON public.user_roles
+ FOR INSERT WITH CHECK (public.is_admin());
+
+CREATE POLICY "Only admins can update role assignments" ON public.user_roles
+ FOR UPDATE USING (public.is_admin());
+
+CREATE POLICY "Only admins can remove role assignments" ON public.user_roles
+ FOR DELETE USING (public.is_admin());
+
+-- Experiment phases policies
+CREATE POLICY "experiment_phases_select_policy" ON public.experiment_phases
+ FOR SELECT
+ TO authenticated
+ USING (true);
+
+CREATE POLICY "experiment_phases_insert_policy" ON public.experiment_phases
+ FOR INSERT
+ TO authenticated
+ WITH CHECK (public.can_manage_experiments());
+
+CREATE POLICY "experiment_phases_update_policy" ON public.experiment_phases
+ FOR UPDATE
+ TO authenticated
+ USING (public.can_manage_experiments())
+ WITH CHECK (public.can_manage_experiments());
+
+CREATE POLICY "experiment_phases_delete_policy" ON public.experiment_phases
+ FOR DELETE
+ TO authenticated
+ USING (public.is_admin());
+
+-- Experiments policies
+CREATE POLICY "experiments_select_policy" ON public.experiments
+ FOR SELECT
+ TO authenticated
+ USING (true);
+
+CREATE POLICY "experiments_insert_policy" ON public.experiments
+ FOR INSERT
+ TO authenticated
+ WITH CHECK (public.can_manage_experiments());
+
+CREATE POLICY "experiments_update_policy" ON public.experiments
+ FOR UPDATE
+ TO authenticated
+ USING (public.can_manage_experiments())
+ WITH CHECK (public.can_manage_experiments());
+
+CREATE POLICY "experiments_delete_policy" ON public.experiments
+ FOR DELETE
+ TO authenticated
+ USING (public.is_admin());
+
+-- Experiment repetitions policies
+CREATE POLICY "Users can view experiment repetitions" ON public.experiment_repetitions
+ FOR SELECT
+ TO authenticated
+ USING (true);
+
+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()
+ );
+
+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()
+ );
+
+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()
+ );
+
+-- Experiment phase drafts policies
+CREATE POLICY "experiment_phase_drafts_select_policy" ON public.experiment_phase_drafts
+ FOR SELECT
+ TO authenticated
+ USING (true);
+
+CREATE POLICY "experiment_phase_drafts_insert_policy" ON public.experiment_phase_drafts
+ FOR INSERT
+ TO authenticated
+ WITH CHECK (user_id = auth.uid());
+
+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()
+ );
+
+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()
+ );
+
+-- Experiment phase data policies
+CREATE POLICY "experiment_phase_data_select_policy" ON public.experiment_phase_data
+ FOR SELECT
+ TO authenticated
+ USING (true);
+
+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()
+ )
+ );
+
+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()
+ )
+ );
+
+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'
+ )
+ );
+
+-- Pecan diameter measurements policies
+CREATE POLICY "pecan_diameter_measurements_select_policy" ON public.pecan_diameter_measurements
+ FOR SELECT
+ TO authenticated
+ USING (true);
+
+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()
+ )
+ );
+
+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()
+ )
+ );
+
+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'
+ )
+ );
+
+-- =============================================
+-- 10. COMMENTS FOR DOCUMENTATION
+-- =============================================
+
+COMMENT ON TABLE public.roles IS 'System roles for user access control';
+COMMENT ON TABLE public.user_profiles IS 'Extended user profiles linked to auth.users';
+COMMENT ON TABLE public.user_roles IS 'Many-to-many relationship between users and roles';
+COMMENT ON TABLE public.experiment_phases IS 'Groups experiments into logical phases for better organization and navigation';
+COMMENT ON TABLE public.experiments IS 'Stores experiment definitions for pecan processing with parameters and status tracking';
+COMMENT ON TABLE public.experiment_repetitions IS 'Individual repetitions of experiment blueprints that can be scheduled and executed';
+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)';
diff --git a/management-dashboard-web-app/supabase/migrations/20250719000001_rbac_schema.sql b/management-dashboard-web-app/supabase/migrations/20250719000001_rbac_schema.sql
deleted file mode 100755
index 9f91091..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250719000001_rbac_schema.sql
+++ /dev/null
@@ -1,55 +0,0 @@
--- RBAC Schema Migration
--- Creates the foundational tables for Role-Based Access Control
-
--- Enable necessary extensions
-CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-
--- Create roles table
-CREATE TABLE IF NOT EXISTS public.roles (
- id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
- name TEXT UNIQUE NOT NULL CHECK (name IN ('admin', 'conductor', 'analyst', 'data recorder')),
- description TEXT NOT NULL,
- created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
- updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
-);
-
--- Create user_profiles table to extend auth.users
-CREATE TABLE IF NOT EXISTS public.user_profiles (
- id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
- email TEXT NOT NULL,
- role_id UUID NOT NULL REFERENCES public.roles(id),
- created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
- updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
-);
-
--- Create indexes for better performance
-CREATE INDEX IF NOT EXISTS idx_user_profiles_role_id ON public.user_profiles(role_id);
-CREATE INDEX IF NOT EXISTS idx_user_profiles_email ON public.user_profiles(email);
-
--- Create updated_at trigger function
-CREATE OR REPLACE FUNCTION public.handle_updated_at()
-RETURNS TRIGGER AS $$
-BEGIN
- NEW.updated_at = NOW();
- RETURN NEW;
-END;
-$$ LANGUAGE plpgsql;
-
--- Create triggers for updated_at
-CREATE TRIGGER set_updated_at_roles
- BEFORE UPDATE ON public.roles
- FOR EACH ROW
- EXECUTE FUNCTION public.handle_updated_at();
-
-CREATE TRIGGER set_updated_at_user_profiles
- BEFORE UPDATE ON public.user_profiles
- FOR EACH ROW
- EXECUTE FUNCTION public.handle_updated_at();
-
--- Insert the four required roles
-INSERT INTO public.roles (name, description) VALUES
- ('admin', 'Full system access with user management capabilities'),
- ('conductor', 'Operational access for conducting experiments and managing data'),
- ('analyst', 'Read-only access for data analysis and reporting'),
- ('data recorder', 'Data entry and recording capabilities')
-ON CONFLICT (name) DO NOTHING;
diff --git a/management-dashboard-web-app/supabase/migrations/20250719000002_rls_policies.sql b/management-dashboard-web-app/supabase/migrations/20250719000002_rls_policies.sql
deleted file mode 100755
index 8c0fd77..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250719000002_rls_policies.sql
+++ /dev/null
@@ -1,63 +0,0 @@
--- Row Level Security Policies for RBAC
--- Implements role-based access control at the database level
-
--- Enable RLS on tables
-ALTER TABLE public.roles ENABLE ROW LEVEL SECURITY;
-ALTER TABLE public.user_profiles ENABLE ROW LEVEL SECURITY;
-
--- Helper function to get current user's role
-CREATE OR REPLACE FUNCTION public.get_user_role()
-RETURNS TEXT AS $$
-BEGIN
- RETURN (
- SELECT r.name
- FROM public.user_profiles up
- JOIN public.roles r ON up.role_id = r.id
- WHERE up.id = auth.uid()
- );
-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 public.get_user_role() = 'admin';
-END;
-$$ LANGUAGE plpgsql SECURITY DEFINER;
-
--- Roles table policies
--- Everyone can read roles (needed for UI dropdowns, etc.)
-CREATE POLICY "Anyone can read roles" ON public.roles
- FOR SELECT USING (true);
-
--- Only admins can modify roles
-CREATE POLICY "Only admins can insert roles" ON public.roles
- FOR INSERT WITH CHECK (public.is_admin());
-
-CREATE POLICY "Only admins can update roles" ON public.roles
- FOR UPDATE USING (public.is_admin());
-
-CREATE POLICY "Only admins can delete roles" ON public.roles
- FOR DELETE USING (public.is_admin());
-
--- User profiles policies
--- Users can read their own profile, admins can read all profiles
-CREATE POLICY "Users can read own profile, admins can read all" ON public.user_profiles
- FOR SELECT USING (
- auth.uid() = id OR public.is_admin()
- );
-
--- Only admins can insert user profiles (user creation)
-CREATE POLICY "Only admins can insert user profiles" ON public.user_profiles
- FOR INSERT WITH CHECK (public.is_admin());
-
--- Users can update their own profile (except role), admins can update any profile
-CREATE POLICY "Users can update own profile, admins can update any" ON public.user_profiles
- FOR UPDATE USING (
- auth.uid() = id OR public.is_admin()
- );
-
--- Only admins can delete user profiles
-CREATE POLICY "Only admins can delete user profiles" ON public.user_profiles
- FOR DELETE USING (public.is_admin());
diff --git a/management-dashboard-web-app/supabase/migrations/20250719000003_seed_admin_user.sql b/management-dashboard-web-app/supabase/migrations/20250719000003_seed_admin_user.sql
deleted file mode 100755
index 406f234..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250719000003_seed_admin_user.sql
+++ /dev/null
@@ -1,65 +0,0 @@
--- Seed Admin User
--- Creates the initial admin user with specified credentials
-
--- Function to create admin user
-CREATE OR REPLACE FUNCTION public.create_admin_user()
-RETURNS VOID AS $$
-DECLARE
- admin_user_id UUID;
- admin_role_id UUID;
-BEGIN
- -- Get admin role ID
- SELECT id INTO admin_role_id FROM public.roles WHERE name = 'admin';
-
- -- Check if admin user already exists
- IF NOT EXISTS (
- SELECT 1 FROM auth.users WHERE email = 's.alireza.v@gmail.com'
- ) THEN
- -- Insert user into auth.users (this simulates user registration)
- -- Note: In production, this would be done through Supabase Auth API
- 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',
- uuid_generate_v4(),
- 'authenticated',
- 'authenticated',
- 's.alireza.v@gmail.com',
- crypt('2517392', gen_salt('bf')), -- Hash the password
- NOW(),
- NOW(),
- NOW(),
- '',
- '',
- '',
- ''
- ) RETURNING id INTO admin_user_id;
-
- -- Insert user profile
- INSERT INTO public.user_profiles (id, email, role_id)
- VALUES (admin_user_id, 's.alireza.v@gmail.com', admin_role_id);
-
- RAISE NOTICE 'Admin user created successfully with email: s.alireza.v@gmail.com';
- ELSE
- RAISE NOTICE 'Admin user already exists';
- END IF;
-END;
-$$ LANGUAGE plpgsql;
-
--- Execute the function to create admin user
-SELECT public.create_admin_user();
-
--- Drop the function as it's no longer needed
-DROP FUNCTION public.create_admin_user();
diff --git a/management-dashboard-web-app/supabase/migrations/20250720000001_multiple_roles_support.sql b/management-dashboard-web-app/supabase/migrations/20250720000001_multiple_roles_support.sql
deleted file mode 100755
index c364d6f..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250720000001_multiple_roles_support.sql
+++ /dev/null
@@ -1,204 +0,0 @@
--- Multiple Roles Support Migration
--- Adds support for multiple roles per user and user status management
-
--- Add status column to user_profiles
-ALTER TABLE public.user_profiles
-ADD COLUMN IF NOT EXISTS status TEXT DEFAULT 'active' CHECK (status IN ('active', 'disabled'));
-
--- Create user_roles junction table for many-to-many relationship
-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)
-);
-
--- Create indexes for better performance
-CREATE INDEX IF NOT EXISTS idx_user_roles_user_id ON public.user_roles(user_id);
-CREATE INDEX IF NOT EXISTS idx_user_roles_role_id ON public.user_roles(role_id);
-CREATE INDEX IF NOT EXISTS idx_user_profiles_status ON public.user_profiles(status);
-
--- Enable RLS on user_roles table
-ALTER TABLE public.user_roles ENABLE ROW LEVEL SECURITY;
-
--- RLS policies for user_roles table
--- Users can read their own role assignments, admins can read all
-CREATE POLICY "Users can read own roles, admins can read all" ON public.user_roles
- FOR SELECT USING (
- user_id = auth.uid() OR public.is_admin()
- );
-
--- Only admins can insert role assignments
-CREATE POLICY "Only admins can assign roles" ON public.user_roles
- FOR INSERT WITH CHECK (public.is_admin());
-
--- Only admins can update role assignments
-CREATE POLICY "Only admins can update role assignments" ON public.user_roles
- FOR UPDATE USING (public.is_admin());
-
--- Only admins can delete role assignments
-CREATE POLICY "Only admins can remove role assignments" ON public.user_roles
- FOR DELETE USING (public.is_admin());
-
--- Update the get_user_role function to return multiple 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;
-
--- Update the is_admin function to work with multiple roles
-CREATE OR REPLACE FUNCTION public.is_admin()
-RETURNS BOOLEAN AS $$
-BEGIN
- RETURN 'admin' = ANY(public.get_user_roles());
-END;
-$$ LANGUAGE plpgsql SECURITY DEFINER;
-
--- 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;
-
--- Function to migrate existing single role assignments to multiple roles
-CREATE OR REPLACE FUNCTION public.migrate_single_roles_to_multiple()
-RETURNS VOID AS $$
-DECLARE
- user_record RECORD;
-BEGIN
- -- Migrate existing role assignments
- FOR user_record IN
- SELECT id, role_id
- FROM public.user_profiles
- WHERE role_id IS NOT NULL
- LOOP
- -- Insert into user_roles if not already exists
- INSERT INTO public.user_roles (user_id, role_id)
- VALUES (user_record.id, user_record.role_id)
- ON CONFLICT (user_id, role_id) DO NOTHING;
- END LOOP;
-
- RAISE NOTICE 'Migration completed: existing role assignments moved to user_roles table';
-END;
-$$ LANGUAGE plpgsql;
-
--- Execute the migration
-SELECT public.migrate_single_roles_to_multiple();
-
--- Drop the migration function as it's no longer needed
-DROP FUNCTION public.migrate_single_roles_to_multiple();
-
--- Function to generate secure temporary password
-CREATE OR REPLACE FUNCTION public.generate_temp_password()
-RETURNS TEXT AS $$
-DECLARE
- chars TEXT := 'ABCDEFGHJKMNPQRSTUVWXYZabcdefghijkmnpqrstuvwxyz23456789';
- result TEXT := '';
- i INTEGER;
-BEGIN
- FOR i IN 1..12 LOOP
- result := result || substr(chars, floor(random() * length(chars) + 1)::integer, 1);
- END LOOP;
- RETURN result;
-END;
-$$ LANGUAGE plpgsql SECURITY DEFINER;
-
--- Function to create user with roles (for admin use)
-CREATE OR REPLACE FUNCTION public.create_user_with_roles(
- user_email TEXT,
- role_names TEXT[],
- temp_password TEXT DEFAULT NULL
-)
-RETURNS JSON AS $$
-DECLARE
- new_user_id UUID;
- role_record RECORD;
- generated_password TEXT;
- result JSON;
-BEGIN
- -- Only admins can create users
- IF NOT public.is_admin() THEN
- RAISE EXCEPTION 'Only administrators can create users';
- END IF;
-
- -- Validate that at least one role is provided
- IF array_length(role_names, 1) IS NULL OR array_length(role_names, 1) = 0 THEN
- RAISE EXCEPTION 'At least one role must be assigned to the user';
- END IF;
-
- -- Generate password if not provided
- IF temp_password IS NULL THEN
- generated_password := public.generate_temp_password();
- ELSE
- generated_password := temp_password;
- END IF;
-
- -- Generate new user ID
- new_user_id := uuid_generate_v4();
-
- -- Insert into auth.users (simulating user creation)
- 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,
- crypt(generated_password, gen_salt('bf')),
- NOW(),
- NOW(),
- NOW(),
- '',
- '',
- '',
- ''
- );
-
- -- Insert user profile
- INSERT INTO public.user_profiles (id, email, status)
- VALUES (new_user_id, user_email, 'active');
-
- -- Assign roles
- FOR role_record IN
- SELECT id FROM public.roles WHERE name = ANY(role_names)
- LOOP
- INSERT INTO public.user_roles (user_id, role_id, assigned_by)
- VALUES (new_user_id, role_record.id, auth.uid());
- END LOOP;
-
- -- Return result
- result := json_build_object(
- 'user_id', new_user_id,
- 'email', user_email,
- 'temp_password', generated_password,
- 'roles', role_names,
- 'status', 'active'
- );
-
- RETURN result;
-END;
-$$ LANGUAGE plpgsql SECURITY DEFINER;
diff --git a/management-dashboard-web-app/supabase/migrations/20250720000002_fix_role_id_constraint.sql b/management-dashboard-web-app/supabase/migrations/20250720000002_fix_role_id_constraint.sql
deleted file mode 100755
index 406f007..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250720000002_fix_role_id_constraint.sql
+++ /dev/null
@@ -1,161 +0,0 @@
--- Fix role_id constraint in user_profiles table
--- Make role_id nullable since we now use user_roles junction table
-
--- Remove the NOT NULL constraint from role_id column
-ALTER TABLE public.user_profiles
-ALTER COLUMN role_id DROP NOT NULL;
-
--- Update the RLS helper functions to work with the new multiple roles system
--- Replace the old get_user_role function that relied on single role_id
-CREATE OR REPLACE FUNCTION public.get_user_role()
-RETURNS TEXT AS $$
-BEGIN
- -- Return the first role found (for backward compatibility)
- -- In practice, use get_user_roles() for multiple roles
- 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;
-
--- Update is_admin function to use the new multiple roles system
-CREATE OR REPLACE FUNCTION public.is_admin()
-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 = 'admin'
- );
-END;
-$$ LANGUAGE plpgsql SECURITY DEFINER;
-
--- Add a function to check if user has any of the specified roles
-CREATE OR REPLACE FUNCTION public.has_any_role(role_names TEXT[])
-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 = ANY(role_names)
- );
-END;
-$$ LANGUAGE plpgsql SECURITY DEFINER;
-
--- Update the create_user_with_roles function to handle potential errors better
-CREATE OR REPLACE FUNCTION public.create_user_with_roles(
- user_email TEXT,
- role_names TEXT[],
- temp_password TEXT DEFAULT NULL
-)
-RETURNS JSON AS $$
-DECLARE
- new_user_id UUID;
- role_record RECORD;
- generated_password TEXT;
- result JSON;
- role_count INTEGER;
-BEGIN
- -- Only admins can create users
- IF NOT public.is_admin() THEN
- RAISE EXCEPTION 'Only administrators can create users';
- END IF;
-
- -- Validate that at least one role is provided
- IF array_length(role_names, 1) IS NULL OR array_length(role_names, 1) = 0 THEN
- RAISE EXCEPTION 'At least one role must be assigned to the user';
- END IF;
-
- -- Validate that all provided roles exist
- SELECT COUNT(*) INTO role_count
- FROM public.roles
- WHERE name = ANY(role_names);
-
- IF role_count != array_length(role_names, 1) THEN
- RAISE EXCEPTION 'One or more specified roles do not exist';
- END IF;
-
- -- Check if user already exists
- IF EXISTS (SELECT 1 FROM auth.users WHERE email = user_email) THEN
- RAISE EXCEPTION 'User with email % already exists', user_email;
- END IF;
-
- -- Generate password if not provided
- IF temp_password IS NULL THEN
- generated_password := public.generate_temp_password();
- ELSE
- generated_password := temp_password;
- END IF;
-
- -- Generate new user ID
- new_user_id := uuid_generate_v4();
-
- -- Insert into auth.users (simulating user creation)
- 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,
- crypt(generated_password, gen_salt('bf')),
- NOW(),
- NOW(),
- NOW(),
- '',
- '',
- '',
- ''
- );
-
- -- Insert user profile (without role_id since it's now nullable)
- INSERT INTO public.user_profiles (id, email, status)
- VALUES (new_user_id, user_email, 'active');
-
- -- Assign roles through the user_roles junction table
- FOR role_record IN
- SELECT id FROM public.roles WHERE name = ANY(role_names)
- LOOP
- INSERT INTO public.user_roles (user_id, role_id, assigned_by)
- VALUES (new_user_id, role_record.id, auth.uid());
- END LOOP;
-
- -- Return result
- result := json_build_object(
- 'user_id', new_user_id,
- 'email', user_email,
- 'temp_password', generated_password,
- 'roles', role_names,
- 'status', 'active'
- );
-
- RETURN result;
-
-EXCEPTION
- WHEN OTHERS THEN
- -- Clean up any partial inserts
- DELETE FROM public.user_roles WHERE user_id = new_user_id;
- DELETE FROM public.user_profiles WHERE id = new_user_id;
- DELETE FROM auth.users WHERE id = new_user_id;
- RAISE;
-END;
-$$ LANGUAGE plpgsql SECURITY DEFINER;
diff --git a/management-dashboard-web-app/supabase/migrations/20250720000003_experiments_table.sql b/management-dashboard-web-app/supabase/migrations/20250720000003_experiments_table.sql
deleted file mode 100755
index 70b1888..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250720000003_experiments_table.sql
+++ /dev/null
@@ -1,103 +0,0 @@
--- Experiments Table Migration
--- Creates the experiments table for managing pecan processing experiment definitions
-
--- Create experiments table
-CREATE TABLE IF NOT EXISTS public.experiments (
- id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
- experiment_number INTEGER UNIQUE NOT NULL,
- reps_required INTEGER NOT NULL CHECK (reps_required > 0),
- soaking_duration_hr FLOAT NOT NULL CHECK (soaking_duration_hr >= 0),
- air_drying_time_min INTEGER NOT NULL CHECK (air_drying_time_min >= 0),
- plate_contact_frequency_hz FLOAT NOT NULL CHECK (plate_contact_frequency_hz > 0),
- throughput_rate_pecans_sec FLOAT NOT NULL CHECK (throughput_rate_pecans_sec > 0),
- crush_amount_in FLOAT NOT NULL CHECK (crush_amount_in >= 0),
- entry_exit_height_diff_in FLOAT NOT NULL,
- schedule_status TEXT NOT NULL DEFAULT 'pending schedule' CHECK (schedule_status IN ('pending schedule', 'scheduled', 'canceled', 'aborted')),
- results_status TEXT NOT NULL DEFAULT 'valid' CHECK (results_status IN ('valid', 'invalid')),
- 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)
-);
-
--- Create indexes for better performance
-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_schedule_status ON public.experiments(schedule_status);
-CREATE INDEX IF NOT EXISTS idx_experiments_results_status ON public.experiments(results_status);
-CREATE INDEX IF NOT EXISTS idx_experiments_completion_status ON public.experiments(completion_status);
-CREATE INDEX IF NOT EXISTS idx_experiments_created_at ON public.experiments(created_at);
-
--- Create trigger for updated_at
-CREATE TRIGGER set_updated_at_experiments
- BEFORE UPDATE ON public.experiments
- FOR EACH ROW
- EXECUTE FUNCTION public.handle_updated_at();
-
--- Enable RLS on experiments table
-ALTER TABLE public.experiments ENABLE ROW LEVEL SECURITY;
-
--- Helper function to check if user has admin or conductor role
-CREATE OR REPLACE FUNCTION public.can_manage_experiments()
-RETURNS BOOLEAN AS $$
-BEGIN
- RETURN EXISTS (
- SELECT 1
- FROM public.user_profiles up
- JOIN public.user_roles ur ON up.id = ur.user_id
- JOIN public.roles r ON ur.role_id = r.id
- WHERE up.id = auth.uid()
- AND r.name IN ('admin', 'conductor')
- );
-END;
-$$ LANGUAGE plpgsql SECURITY DEFINER;
-
--- RLS Policies for experiments table
-
--- Policy: All authenticated users can view experiments
-CREATE POLICY "experiments_select_policy" ON public.experiments
- FOR SELECT
- TO authenticated
- USING (true);
-
--- Policy: Only admin and conductor roles can insert experiments
-CREATE POLICY "experiments_insert_policy" ON public.experiments
- FOR INSERT
- TO authenticated
- WITH CHECK (public.can_manage_experiments());
-
--- Policy: Only admin and conductor roles can update experiments
-CREATE POLICY "experiments_update_policy" ON public.experiments
- FOR UPDATE
- TO authenticated
- USING (public.can_manage_experiments())
- WITH CHECK (public.can_manage_experiments());
-
--- Policy: Only admin role can delete experiments
-CREATE POLICY "experiments_delete_policy" ON public.experiments
- FOR DELETE
- TO authenticated
- USING (
- EXISTS (
- SELECT 1
- FROM public.user_profiles up
- JOIN public.user_roles ur ON up.id = ur.user_id
- JOIN public.roles r ON ur.role_id = r.id
- WHERE up.id = auth.uid()
- AND r.name = 'admin'
- )
- );
-
--- Add comment to table for documentation
-COMMENT ON TABLE public.experiments IS 'Stores experiment definitions for pecan processing with parameters and status tracking';
-COMMENT ON COLUMN public.experiments.experiment_number IS 'User-defined unique experiment identifier';
-COMMENT ON COLUMN public.experiments.reps_required IS 'Total number of repetitions needed for this experiment';
-COMMENT ON COLUMN public.experiments.soaking_duration_hr IS 'Soaking process duration in hours';
-COMMENT ON COLUMN public.experiments.air_drying_time_min IS 'Air drying duration in minutes';
-COMMENT ON COLUMN public.experiments.plate_contact_frequency_hz IS 'JC Cracker machine plate contact frequency in Hz';
-COMMENT ON COLUMN public.experiments.throughput_rate_pecans_sec IS 'Pecan processing rate in pecans per second';
-COMMENT ON COLUMN public.experiments.crush_amount_in IS 'Crushing amount in thousandths of an inch';
-COMMENT ON COLUMN public.experiments.entry_exit_height_diff_in IS 'Height difference between entry/exit points in inches (can be negative)';
-COMMENT ON COLUMN public.experiments.schedule_status IS 'Current scheduling status of the experiment';
-COMMENT ON COLUMN public.experiments.results_status IS 'Validity status of experiment results';
-COMMENT ON COLUMN public.experiments.completion_status IS 'Boolean flag indicating if the experiment has been completed';
diff --git a/management-dashboard-web-app/supabase/migrations/20250721000001_add_scheduled_date.sql b/management-dashboard-web-app/supabase/migrations/20250721000001_add_scheduled_date.sql
deleted file mode 100755
index f34e5f0..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250721000001_add_scheduled_date.sql
+++ /dev/null
@@ -1,12 +0,0 @@
--- Add scheduled_date field to experiments table
--- This migration adds support for storing when experiments are scheduled to run
-
--- Add scheduled_date column to experiments table
-ALTER TABLE public.experiments
-ADD COLUMN IF NOT EXISTS scheduled_date TIMESTAMP WITH TIME ZONE;
-
--- Create index for better performance when querying by scheduled date
-CREATE INDEX IF NOT EXISTS idx_experiments_scheduled_date ON public.experiments(scheduled_date);
-
--- Add comment for documentation
-COMMENT ON COLUMN public.experiments.scheduled_date IS 'Date and time when the experiment is scheduled to run';
diff --git a/management-dashboard-web-app/supabase/migrations/20250724000001_experiment_repetitions_system.sql b/management-dashboard-web-app/supabase/migrations/20250724000001_experiment_repetitions_system.sql
deleted file mode 100755
index 3549f71..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250724000001_experiment_repetitions_system.sql
+++ /dev/null
@@ -1,131 +0,0 @@
--- 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
--- All authenticated users can view all experiment repetitions
-CREATE POLICY "Users can view experiment repetitions" ON public.experiment_repetitions
- FOR SELECT
- TO authenticated
- USING (true);
-
--- 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
diff --git a/management-dashboard-web-app/supabase/migrations/20250725000001_experiment_data_entry_system.sql b/management-dashboard-web-app/supabase/migrations/20250725000001_experiment_data_entry_system.sql
deleted file mode 100755
index 2114ad3..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250725000001_experiment_data_entry_system.sql
+++ /dev/null
@@ -1,332 +0,0 @@
--- 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();
diff --git a/management-dashboard-web-app/supabase/migrations/20250725000003_fix_draft_constraints.sql b/management-dashboard-web-app/supabase/migrations/20250725000003_fix_draft_constraints.sql
deleted file mode 100755
index cc0542e..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250725000003_fix_draft_constraints.sql
+++ /dev/null
@@ -1,17 +0,0 @@
--- 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';
diff --git a/management-dashboard-web-app/supabase/migrations/20250728000001_fix_repetitions_visibility.sql b/management-dashboard-web-app/supabase/migrations/20250728000001_fix_repetitions_visibility.sql
deleted file mode 100755
index 5756ba0..0000000
--- a/management-dashboard-web-app/supabase/migrations/20250728000001_fix_repetitions_visibility.sql
+++ /dev/null
@@ -1,12 +0,0 @@
--- Fix experiment repetitions visibility for all users
--- This migration updates the RLS policy to allow all authenticated users to view all experiment repetitions
--- Previously, users could only see repetitions for experiments they created
-
--- Drop the existing restrictive policy
-DROP POLICY IF EXISTS "Users can view experiment repetitions" ON public.experiment_repetitions;
-
--- Create new policy that allows all authenticated users to view all repetitions
-CREATE POLICY "Users can view experiment repetitions" ON public.experiment_repetitions
- FOR SELECT
- TO authenticated
- USING (true);
diff --git a/management-dashboard-web-app/supabase/seed.sql b/management-dashboard-web-app/supabase/seed.sql
index 7448705..79b6a2f 100755
--- a/management-dashboard-web-app/supabase/seed.sql
+++ b/management-dashboard-web-app/supabase/seed.sql
@@ -1,9 +1,88 @@
--- Seed data for testing experiment repetitions functionality
+-- Seed Data for USDA Vision Pecan Experiments System
+-- This file populates the database with initial data
+
+-- =============================================
+-- 1. INSERT ROLES
+-- =============================================
+
+INSERT INTO public.roles (name, description) VALUES
+('admin', 'System administrator with full access to all features'),
+('conductor', 'Experiment conductor who can manage experiments and view all data'),
+('analyst', 'Data analyst who can view and analyze experiment results'),
+('data recorder', 'Data entry specialist who can record experiment measurements');
+
+-- =============================================
+-- 2. CREATE ADMIN USER
+-- =============================================
+
+-- Create admin 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',
+ uuid_generate_v4(),
+ 'authenticated',
+ 'authenticated',
+ 's.alireza.v@gmail.com',
+ crypt('admin123', gen_salt('bf')),
+ NOW(),
+ NOW(),
+ NOW(),
+ '',
+ '',
+ '',
+ ''
+);
+
+-- Create user profile
+INSERT INTO public.user_profiles (id, email, status)
+SELECT id, email, 'active'
+FROM auth.users
+WHERE email = 's.alireza.v@gmail.com'
+;
+
+-- Assign admin role
+INSERT INTO public.user_roles (user_id, role_id, assigned_by)
+SELECT
+ up.id,
+ r.id,
+ up.id
+FROM public.user_profiles up
+CROSS JOIN public.roles r
+WHERE up.email = 's.alireza.v@gmail.com'
+AND r.name = 'admin'
+;
+
+-- =============================================
+-- 3. CREATE EXPERIMENT PHASES
+-- =============================================
+
+-- Create "Phase 2 of JC Experiments" phase
+INSERT INTO public.experiment_phases (name, description, created_by)
+SELECT
+ 'Phase 2 of JC Experiments',
+ 'Second phase of JC Cracker experiments for pecan processing optimization',
+ up.id
+FROM public.user_profiles up
+WHERE up.email = 's.alireza.v@gmail.com'
+;
+
+-- =============================================
+-- 4. INSERT EXPERIMENTS (First 10 as example)
+-- =============================================
--- 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,
@@ -14,117 +93,53 @@ INSERT INTO public.experiments (
crush_amount_in,
entry_exit_height_diff_in,
results_status,
- created_by
-) 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'));
-
--- 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,
+ phase_id,
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'));
\ No newline at end of file
+(1, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(2, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(3, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(4, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(5, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(6, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(7, 3, 3.0, 60, 10.0, 1.8, 0.175, 1.0, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(8, 3, 1.5, 20, 18.0, 3.0, 0.100, 0.25, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(9, 3, 2.0, 30, 15.0, 2.5, 0.125, 0.5, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com')),
+(10, 3, 2.5, 45, 12.0, 2.0, 0.150, 0.75, 'valid', false,
+ (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments'),
+ (SELECT id FROM public.user_profiles WHERE email = 's.alireza.v@gmail.com'))
+;
+
+-- =============================================
+-- 5. CREATE SAMPLE EXPERIMENT REPETITIONS
+-- =============================================
+
+-- Create repetitions for first 5 experiments as examples
+INSERT INTO public.experiment_repetitions (experiment_id, repetition_number, created_by)
+SELECT
+ e.id,
+ rep_num,
+ e.created_by
+FROM public.experiments e
+CROSS JOIN generate_series(1, 3) AS rep_num
+WHERE e.experiment_number <= 5
+;
\ No newline at end of file
diff --git a/management-dashboard-web-app/test_migration.sql b/management-dashboard-web-app/test_migration.sql
new file mode 100644
index 0000000..edc5378
--- /dev/null
+++ b/management-dashboard-web-app/test_migration.sql
@@ -0,0 +1,14 @@
+-- Test migration to create experiment_phases table
+CREATE TABLE IF NOT EXISTS public.experiment_phases (
+ id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
+ name TEXT NOT NULL UNIQUE,
+ description TEXT,
+ created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
+ updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
+ created_by UUID NOT NULL
+);
+
+-- Insert test data
+INSERT INTO public.experiment_phases (name, description, created_by)
+VALUES ('Phase 2 of JC Experiments', 'Second phase of JC Cracker experiments', '00000000-0000-0000-0000-000000000000')
+ON CONFLICT (name) DO NOTHING;