Refactor experiment management and update data structures
- Renamed columns in the experimental run sheet CSV for clarity. - Updated the ExperimentForm component to include new fields for weight per repetition and additional parameters specific to Meyer Cracker experiments. - Enhanced the data entry logic to handle new experiment phases and machine types. - Refactored repetition scheduling logic to use scheduled_date instead of schedule_status for better clarity in status representation. - Improved the user interface for displaying experiment phases and their associated statuses. - Removed outdated seed data and updated database migration scripts to reflect the new schema changes.
This commit is contained in:
File diff suppressed because it is too large
Load Diff
@@ -72,7 +72,78 @@ CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_scheduled_start ON p
|
||||
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_created_by ON public.experiment_phase_assignments(created_by);
|
||||
|
||||
-- =============================================
|
||||
-- 4. FUNCTIONS FOR OVERLAP PREVENTION
|
||||
-- 4. UTILITY FUNCTIONS
|
||||
-- =============================================
|
||||
|
||||
-- Function to handle updated_at timestamp
|
||||
CREATE OR REPLACE FUNCTION public.handle_updated_at()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Helper function to get current user's roles
|
||||
CREATE OR REPLACE FUNCTION public.get_user_roles()
|
||||
RETURNS TEXT[] AS $$
|
||||
BEGIN
|
||||
RETURN ARRAY(
|
||||
SELECT r.name
|
||||
FROM public.user_roles ur
|
||||
JOIN public.roles r ON ur.role_id = r.id
|
||||
WHERE ur.user_id = auth.uid()
|
||||
);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
-- Helper function to get current user's first role (for backward compatibility)
|
||||
CREATE OR REPLACE FUNCTION public.get_user_role()
|
||||
RETURNS TEXT AS $$
|
||||
BEGIN
|
||||
-- Return the first role found (for backward compatibility)
|
||||
RETURN (
|
||||
SELECT r.name
|
||||
FROM public.user_roles ur
|
||||
JOIN public.roles r ON ur.role_id = r.id
|
||||
WHERE ur.user_id = auth.uid()
|
||||
LIMIT 1
|
||||
);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
-- Helper function to check if user is admin
|
||||
CREATE OR REPLACE FUNCTION public.is_admin()
|
||||
RETURNS BOOLEAN AS $$
|
||||
BEGIN
|
||||
RETURN 'admin' = ANY(public.get_user_roles());
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
-- Helper function to check if user has specific role
|
||||
CREATE OR REPLACE FUNCTION public.has_role(role_name TEXT)
|
||||
RETURNS BOOLEAN AS $$
|
||||
BEGIN
|
||||
RETURN role_name = ANY(public.get_user_roles());
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
-- Helper function to check if user can manage experiments
|
||||
CREATE OR REPLACE FUNCTION public.can_manage_experiments()
|
||||
RETURNS BOOLEAN AS $$
|
||||
BEGIN
|
||||
RETURN EXISTS (
|
||||
SELECT 1
|
||||
FROM public.user_roles ur
|
||||
JOIN public.roles r ON ur.role_id = r.id
|
||||
WHERE ur.user_id = auth.uid()
|
||||
AND r.name IN ('admin', 'conductor')
|
||||
);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
-- =============================================
|
||||
-- 5. FUNCTIONS FOR OVERLAP PREVENTION
|
||||
-- =============================================
|
||||
|
||||
-- Function to check for overlapping availabilities
|
||||
@@ -156,7 +227,7 @@ END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- =============================================
|
||||
-- 5. TRIGGERS
|
||||
-- 6. TRIGGERS
|
||||
-- =============================================
|
||||
|
||||
-- Create trigger for updated_at on conductor_availability
|
||||
@@ -239,7 +310,7 @@ END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
-- =============================================
|
||||
-- 7. ROW LEVEL SECURITY (RLS)
|
||||
-- 8. ROW LEVEL SECURITY (RLS)
|
||||
-- =============================================
|
||||
|
||||
-- Enable RLS on new tables
|
||||
|
||||
@@ -1,49 +0,0 @@
|
||||
-- Add password reset function for admin use
|
||||
-- This migration adds a function to reset user passwords back to the default "password123"
|
||||
|
||||
-- Function to reset user password (admin only)
|
||||
CREATE OR REPLACE FUNCTION public.reset_user_password(
|
||||
target_user_id UUID
|
||||
)
|
||||
RETURNS JSON AS $$
|
||||
DECLARE
|
||||
user_email TEXT;
|
||||
result JSON;
|
||||
BEGIN
|
||||
-- Only admins can reset passwords
|
||||
IF NOT public.is_admin() THEN
|
||||
RAISE EXCEPTION 'Only administrators can reset user passwords';
|
||||
END IF;
|
||||
|
||||
-- Check if target user exists
|
||||
SELECT email INTO user_email
|
||||
FROM public.user_profiles
|
||||
WHERE id = target_user_id;
|
||||
|
||||
IF user_email IS NULL THEN
|
||||
RAISE EXCEPTION 'User not found';
|
||||
END IF;
|
||||
|
||||
-- Update the password in auth.users table
|
||||
UPDATE auth.users
|
||||
SET
|
||||
encrypted_password = crypt('password123', gen_salt('bf')),
|
||||
updated_at = NOW()
|
||||
WHERE id = target_user_id;
|
||||
|
||||
-- Return result
|
||||
result := json_build_object(
|
||||
'user_id', target_user_id,
|
||||
'email', user_email,
|
||||
'new_password', 'password123',
|
||||
'reset_at', NOW()
|
||||
);
|
||||
|
||||
RETURN result;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RAISE;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
@@ -0,0 +1,185 @@
|
||||
-- Migration: Change experiments table to use composite primary key (experiment_number, phase_id)
|
||||
-- This allows each phase to have its own experiment numbering starting from 1
|
||||
|
||||
-- =============================================
|
||||
-- 1. DROP EXISTING FOREIGN KEY CONSTRAINTS
|
||||
-- =============================================
|
||||
|
||||
-- Drop foreign key constraints that reference experiments table
|
||||
ALTER TABLE public.experiment_repetitions DROP CONSTRAINT IF EXISTS experiment_repetitions_experiment_id_fkey;
|
||||
ALTER TABLE public.soaking DROP CONSTRAINT IF EXISTS soaking_experiment_id_fkey;
|
||||
ALTER TABLE public.airdrying DROP CONSTRAINT IF EXISTS airdrying_experiment_id_fkey;
|
||||
ALTER TABLE public.cracking DROP CONSTRAINT IF EXISTS cracking_experiment_id_fkey;
|
||||
ALTER TABLE public.shelling DROP CONSTRAINT IF EXISTS shelling_experiment_id_fkey;
|
||||
ALTER TABLE public.conductor_availability DROP CONSTRAINT IF EXISTS conductor_availability_experiment_id_fkey;
|
||||
|
||||
-- =============================================
|
||||
-- 2. MODIFY EXPERIMENTS TABLE
|
||||
-- =============================================
|
||||
|
||||
-- Drop the existing primary key and unique constraint
|
||||
ALTER TABLE public.experiments DROP CONSTRAINT IF EXISTS experiments_pkey;
|
||||
ALTER TABLE public.experiments DROP CONSTRAINT IF EXISTS experiments_experiment_number_key;
|
||||
|
||||
-- Make phase_id NOT NULL since it's now part of the primary key
|
||||
ALTER TABLE public.experiments ALTER COLUMN phase_id SET NOT NULL;
|
||||
|
||||
-- Add composite primary key
|
||||
ALTER TABLE public.experiments ADD CONSTRAINT experiments_pkey PRIMARY KEY (experiment_number, phase_id);
|
||||
|
||||
-- =============================================
|
||||
-- 3. UPDATE FOREIGN KEY COLUMNS
|
||||
-- =============================================
|
||||
|
||||
-- Add phase_id columns to tables that reference experiments
|
||||
ALTER TABLE public.experiment_repetitions ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
||||
ALTER TABLE public.soaking ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
||||
ALTER TABLE public.airdrying ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
||||
ALTER TABLE public.cracking ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
||||
ALTER TABLE public.shelling ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
||||
ALTER TABLE public.conductor_availability ADD COLUMN IF NOT EXISTS experiment_phase_id UUID;
|
||||
|
||||
-- Populate the phase_id columns from the experiments table
|
||||
UPDATE public.experiment_repetitions
|
||||
SET experiment_phase_id = e.phase_id
|
||||
FROM public.experiments e
|
||||
WHERE experiment_repetitions.experiment_id = e.id;
|
||||
|
||||
UPDATE public.soaking
|
||||
SET experiment_phase_id = e.phase_id
|
||||
FROM public.experiments e
|
||||
WHERE soaking.experiment_id = e.id;
|
||||
|
||||
UPDATE public.airdrying
|
||||
SET experiment_phase_id = e.phase_id
|
||||
FROM public.experiments e
|
||||
WHERE airdrying.experiment_id = e.id;
|
||||
|
||||
UPDATE public.cracking
|
||||
SET experiment_phase_id = e.phase_id
|
||||
FROM public.experiments e
|
||||
WHERE cracking.experiment_id = e.id;
|
||||
|
||||
UPDATE public.shelling
|
||||
SET experiment_phase_id = e.phase_id
|
||||
FROM public.experiments e
|
||||
WHERE shelling.experiment_id = e.id;
|
||||
|
||||
UPDATE public.conductor_availability
|
||||
SET experiment_phase_id = e.phase_id
|
||||
FROM public.experiments e
|
||||
WHERE conductor_availability.experiment_id = e.id;
|
||||
|
||||
-- Make the phase_id columns NOT NULL
|
||||
ALTER TABLE public.experiment_repetitions ALTER COLUMN experiment_phase_id SET NOT NULL;
|
||||
ALTER TABLE public.soaking ALTER COLUMN experiment_phase_id SET NOT NULL;
|
||||
ALTER TABLE public.airdrying ALTER COLUMN experiment_phase_id SET NOT NULL;
|
||||
ALTER TABLE public.cracking ALTER COLUMN experiment_phase_id SET NOT NULL;
|
||||
ALTER TABLE public.shelling ALTER COLUMN experiment_phase_id SET NOT NULL;
|
||||
ALTER TABLE public.conductor_availability ALTER COLUMN experiment_phase_id SET NOT NULL;
|
||||
|
||||
-- =============================================
|
||||
-- 4. ADD NEW FOREIGN KEY CONSTRAINTS
|
||||
-- =============================================
|
||||
|
||||
-- Add foreign key constraints using composite key
|
||||
ALTER TABLE public.experiment_repetitions
|
||||
ADD CONSTRAINT experiment_repetitions_experiment_fkey
|
||||
FOREIGN KEY (experiment_id, experiment_phase_id)
|
||||
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE public.soaking
|
||||
ADD CONSTRAINT soaking_experiment_fkey
|
||||
FOREIGN KEY (experiment_id, experiment_phase_id)
|
||||
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE public.airdrying
|
||||
ADD CONSTRAINT airdrying_experiment_fkey
|
||||
FOREIGN KEY (experiment_id, experiment_phase_id)
|
||||
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE public.cracking
|
||||
ADD CONSTRAINT cracking_experiment_fkey
|
||||
FOREIGN KEY (experiment_id, experiment_phase_id)
|
||||
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE public.shelling
|
||||
ADD CONSTRAINT shelling_experiment_fkey
|
||||
FOREIGN KEY (experiment_id, experiment_phase_id)
|
||||
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE public.conductor_availability
|
||||
ADD CONSTRAINT conductor_availability_experiment_fkey
|
||||
FOREIGN KEY (experiment_id, experiment_phase_id)
|
||||
REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE;
|
||||
|
||||
-- =============================================
|
||||
-- 5. UPDATE UNIQUE CONSTRAINTS
|
||||
-- =============================================
|
||||
|
||||
-- Update unique constraints to use composite key
|
||||
ALTER TABLE public.experiment_repetitions
|
||||
DROP CONSTRAINT IF EXISTS experiment_repetitions_experiment_id_repetition_number_key;
|
||||
|
||||
ALTER TABLE public.experiment_repetitions
|
||||
ADD CONSTRAINT experiment_repetitions_experiment_repetition_key
|
||||
UNIQUE (experiment_id, experiment_phase_id, repetition_number);
|
||||
|
||||
-- Update unique constraints for phase tables
|
||||
ALTER TABLE public.soaking
|
||||
DROP CONSTRAINT IF EXISTS unique_soaking_per_experiment;
|
||||
|
||||
ALTER TABLE public.soaking
|
||||
ADD CONSTRAINT unique_soaking_per_experiment
|
||||
UNIQUE (experiment_id, experiment_phase_id);
|
||||
|
||||
ALTER TABLE public.airdrying
|
||||
DROP CONSTRAINT IF EXISTS unique_airdrying_per_experiment;
|
||||
|
||||
ALTER TABLE public.airdrying
|
||||
ADD CONSTRAINT unique_airdrying_per_experiment
|
||||
UNIQUE (experiment_id, experiment_phase_id);
|
||||
|
||||
ALTER TABLE public.cracking
|
||||
DROP CONSTRAINT IF EXISTS unique_cracking_per_experiment;
|
||||
|
||||
ALTER TABLE public.cracking
|
||||
ADD CONSTRAINT unique_cracking_per_experiment
|
||||
UNIQUE (experiment_id, experiment_phase_id);
|
||||
|
||||
ALTER TABLE public.shelling
|
||||
DROP CONSTRAINT IF EXISTS unique_shelling_per_experiment;
|
||||
|
||||
ALTER TABLE public.shelling
|
||||
ADD CONSTRAINT unique_shelling_per_experiment
|
||||
UNIQUE (experiment_id, experiment_phase_id);
|
||||
|
||||
-- =============================================
|
||||
-- 6. UPDATE INDEXES
|
||||
-- =============================================
|
||||
|
||||
-- Drop old indexes
|
||||
DROP INDEX IF EXISTS idx_soaking_experiment_id;
|
||||
DROP INDEX IF EXISTS idx_airdrying_experiment_id;
|
||||
DROP INDEX IF EXISTS idx_cracking_experiment_id;
|
||||
DROP INDEX IF EXISTS idx_shelling_experiment_id;
|
||||
|
||||
-- Create new composite indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_soaking_experiment_composite ON public.soaking(experiment_id, experiment_phase_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_airdrying_experiment_composite ON public.airdrying(experiment_id, experiment_phase_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_cracking_experiment_composite ON public.cracking(experiment_id, experiment_phase_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_shelling_experiment_composite ON public.shelling(experiment_id, experiment_phase_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_composite ON public.experiment_repetitions(experiment_id, experiment_phase_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_conductor_availability_experiment_composite ON public.conductor_availability(experiment_id, experiment_phase_id);
|
||||
|
||||
-- =============================================
|
||||
-- 7. UPDATE EXPERIMENTS TABLE FOREIGN KEY REFERENCES
|
||||
-- =============================================
|
||||
|
||||
-- The experiments table has foreign key references to phase tables
|
||||
-- These need to be updated to use the new composite key structure
|
||||
-- We'll need to update these after the phase tables are updated
|
||||
|
||||
-- Note: The soaking_id, airdrying_id, cracking_id, shelling_id columns in experiments table
|
||||
-- will need to be updated to reference the new composite structure
|
||||
-- This will be handled in the seed files update
|
||||
@@ -1,12 +0,0 @@
|
||||
-- Add first_name and last_name fields to user_profiles table
|
||||
-- This migration adds name fields to store user's first and last names
|
||||
|
||||
-- Add first_name and last_name columns to user_profiles table
|
||||
ALTER TABLE public.user_profiles
|
||||
ADD COLUMN first_name TEXT,
|
||||
ADD COLUMN last_name TEXT;
|
||||
|
||||
-- Add comments for documentation
|
||||
COMMENT ON COLUMN public.user_profiles.first_name IS 'User first name';
|
||||
COMMENT ON COLUMN public.user_profiles.last_name IS 'User last name';
|
||||
|
||||
@@ -0,0 +1,13 @@
|
||||
-- Convert soaking duration to hours instead of minutes
|
||||
-- 1) Rename column
|
||||
ALTER TABLE public.soaking RENAME COLUMN soaking_duration_minutes TO soaking_duration_hours;
|
||||
|
||||
-- 2) Change type to double precision to allow fractional hours
|
||||
ALTER TABLE public.soaking ALTER COLUMN soaking_duration_hours TYPE DOUBLE PRECISION USING soaking_duration_hours::double precision;
|
||||
|
||||
-- 3) Convert existing data (currently minutes) to hours
|
||||
UPDATE public.soaking SET soaking_duration_hours = soaking_duration_hours / 60.0;
|
||||
|
||||
-- 4) Ensure CHECK constraint (> 0)
|
||||
ALTER TABLE public.soaking DROP CONSTRAINT IF EXISTS soaking_soaking_duration_minutes_check;
|
||||
ALTER TABLE public.soaking ADD CONSTRAINT soaking_soaking_duration_hours_check CHECK (soaking_duration_hours > 0);
|
||||
@@ -1,62 +0,0 @@
|
||||
-- Add change password function for users
|
||||
-- This migration adds a function to allow users to change their own password
|
||||
|
||||
-- Function to change user password (user can only change their own password)
|
||||
CREATE OR REPLACE FUNCTION public.change_user_password(
|
||||
current_password TEXT,
|
||||
new_password TEXT
|
||||
)
|
||||
RETURNS JSON AS $$
|
||||
DECLARE
|
||||
user_id UUID;
|
||||
user_email TEXT;
|
||||
result JSON;
|
||||
BEGIN
|
||||
-- Get current user ID
|
||||
user_id := auth.uid();
|
||||
|
||||
IF user_id IS NULL THEN
|
||||
RAISE EXCEPTION 'User not authenticated';
|
||||
END IF;
|
||||
|
||||
-- Get user email
|
||||
SELECT email INTO user_email
|
||||
FROM public.user_profiles
|
||||
WHERE id = user_id;
|
||||
|
||||
IF user_email IS NULL THEN
|
||||
RAISE EXCEPTION 'User profile not found';
|
||||
END IF;
|
||||
|
||||
-- Verify current password
|
||||
IF NOT EXISTS (
|
||||
SELECT 1
|
||||
FROM auth.users
|
||||
WHERE id = user_id
|
||||
AND encrypted_password = crypt(current_password, encrypted_password)
|
||||
) THEN
|
||||
RAISE EXCEPTION 'Current password is incorrect';
|
||||
END IF;
|
||||
|
||||
-- Update the password in auth.users table
|
||||
UPDATE auth.users
|
||||
SET
|
||||
encrypted_password = crypt(new_password, gen_salt('bf')),
|
||||
updated_at = NOW()
|
||||
WHERE id = user_id;
|
||||
|
||||
-- Return result
|
||||
result := json_build_object(
|
||||
'user_id', user_id,
|
||||
'email', user_email,
|
||||
'password_changed_at', NOW()
|
||||
);
|
||||
|
||||
RETURN result;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RAISE;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
@@ -0,0 +1,27 @@
|
||||
-- Migration: Add cracking_machine_type_id to experiment_phases
|
||||
-- Adds optional reference to machine_types so a phase can specify the cracking machine
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- 1) Add column (nullable to avoid breaking existing data)
|
||||
ALTER TABLE public.experiment_phases
|
||||
ADD COLUMN IF NOT EXISTS cracking_machine_type_id UUID NULL;
|
||||
|
||||
-- 2) Add foreign key to machine_types
|
||||
ALTER TABLE public.experiment_phases
|
||||
ADD CONSTRAINT fk_experiment_phases_cracking_machine_type
|
||||
FOREIGN KEY (cracking_machine_type_id)
|
||||
REFERENCES public.machine_types(id)
|
||||
ON DELETE SET NULL;
|
||||
|
||||
-- 3) Optional: index for lookup/filtering
|
||||
CREATE INDEX IF NOT EXISTS idx_experiment_phases_cracking_machine_type_id
|
||||
ON public.experiment_phases (cracking_machine_type_id);
|
||||
|
||||
COMMIT;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
@@ -0,0 +1,32 @@
|
||||
-- Migration: Require cracking_machine_type_id when has_cracking is true
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- Drop existing constraint if it exists (for re-runs)
|
||||
DO $$
|
||||
BEGIN
|
||||
IF EXISTS (
|
||||
SELECT 1 FROM pg_constraint c
|
||||
JOIN pg_class t ON c.conrelid = t.oid
|
||||
WHERE t.relname = 'experiment_phases'
|
||||
AND c.conname = 'ck_experiment_phases_machine_required_when_cracking'
|
||||
) THEN
|
||||
ALTER TABLE public.experiment_phases
|
||||
DROP CONSTRAINT ck_experiment_phases_machine_required_when_cracking;
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- Add check: if has_cracking then cracking_machine_type_id must not be null
|
||||
ALTER TABLE public.experiment_phases
|
||||
ADD CONSTRAINT ck_experiment_phases_machine_required_when_cracking
|
||||
CHECK (
|
||||
(has_cracking = false) OR (cracking_machine_type_id IS NOT NULL)
|
||||
);
|
||||
|
||||
COMMIT;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
Reference in New Issue
Block a user