Files
usda-vision/management-dashboard-web-app/supabase/migrations/20250102000001_add_conductor_availability.sql
salirezav aaeb164a32 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.
2025-09-24 14:27:28 -04:00

413 lines
17 KiB
PL/PgSQL

-- Add Conductor Availability and Experiment Phase Assignment Tables
-- This migration adds tables for conductor availability management and future experiment scheduling
-- =============================================
-- 1. CONDUCTOR AVAILABILITY TABLE
-- =============================================
-- Create conductor_availability table
CREATE TABLE IF NOT EXISTS public.conductor_availability (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID NOT NULL REFERENCES public.user_profiles(id) ON DELETE CASCADE,
available_from TIMESTAMP WITH TIME ZONE NOT NULL,
available_to TIMESTAMP WITH TIME ZONE NOT NULL,
notes TEXT, -- Optional notes about the availability
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'cancelled')),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by UUID NOT NULL REFERENCES public.user_profiles(id),
-- Ensure available_to is after available_from
CONSTRAINT valid_time_range CHECK (available_to > available_from),
-- Ensure availability is in the future (can be modified if needed for past records)
CONSTRAINT future_availability CHECK (available_from >= NOW() - INTERVAL '1 day')
);
-- =============================================
-- 2. EXPERIMENT PHASE ASSIGNMENTS TABLE (Future Scheduling)
-- =============================================
-- Create experiment_phase_assignments table for scheduling conductors to experiment phases
CREATE TABLE IF NOT EXISTS public.experiment_phase_assignments (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE,
repetition_id UUID NOT NULL REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE,
conductor_id UUID NOT NULL REFERENCES public.user_profiles(id) ON DELETE CASCADE,
phase_name TEXT NOT NULL CHECK (phase_name IN ('pre-soaking', 'air-drying', 'cracking', 'shelling')),
scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL,
scheduled_end_time TIMESTAMP WITH TIME ZONE NOT NULL,
status TEXT NOT NULL DEFAULT 'scheduled' CHECK (status IN ('scheduled', 'in-progress', 'completed', 'cancelled')),
notes TEXT, -- Optional notes about the assignment
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 scheduled_end_time is after scheduled_start_time
CONSTRAINT valid_scheduled_time_range CHECK (scheduled_end_time > scheduled_start_time),
-- Ensure unique assignment per conductor per phase per repetition
CONSTRAINT unique_conductor_phase_assignment UNIQUE (repetition_id, conductor_id, phase_name)
);
-- =============================================
-- 3. INDEXES FOR PERFORMANCE
-- =============================================
-- Conductor availability indexes
CREATE INDEX IF NOT EXISTS idx_conductor_availability_user_id ON public.conductor_availability(user_id);
CREATE INDEX IF NOT EXISTS idx_conductor_availability_available_from ON public.conductor_availability(available_from);
CREATE INDEX IF NOT EXISTS idx_conductor_availability_available_to ON public.conductor_availability(available_to);
CREATE INDEX IF NOT EXISTS idx_conductor_availability_status ON public.conductor_availability(status);
CREATE INDEX IF NOT EXISTS idx_conductor_availability_created_by ON public.conductor_availability(created_by);
CREATE INDEX IF NOT EXISTS idx_conductor_availability_time_range ON public.conductor_availability(available_from, available_to);
-- Experiment phase assignments indexes
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_experiment_id ON public.experiment_phase_assignments(experiment_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_repetition_id ON public.experiment_phase_assignments(repetition_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_conductor_id ON public.experiment_phase_assignments(conductor_id);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_phase_name ON public.experiment_phase_assignments(phase_name);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_status ON public.experiment_phase_assignments(status);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_scheduled_start ON public.experiment_phase_assignments(scheduled_start_time);
CREATE INDEX IF NOT EXISTS idx_experiment_phase_assignments_created_by ON public.experiment_phase_assignments(created_by);
-- =============================================
-- 4. UTILITY FUNCTIONS
-- =============================================
-- Function to handle updated_at timestamp
CREATE OR REPLACE FUNCTION public.handle_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Helper function to get current user's roles
CREATE OR REPLACE FUNCTION public.get_user_roles()
RETURNS TEXT[] AS $$
BEGIN
RETURN ARRAY(
SELECT r.name
FROM public.user_roles ur
JOIN public.roles r ON ur.role_id = r.id
WHERE ur.user_id = auth.uid()
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to get current user's first role (for backward compatibility)
CREATE OR REPLACE FUNCTION public.get_user_role()
RETURNS TEXT AS $$
BEGIN
-- Return the first role found (for backward compatibility)
RETURN (
SELECT r.name
FROM public.user_roles ur
JOIN public.roles r ON ur.role_id = r.id
WHERE ur.user_id = auth.uid()
LIMIT 1
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to check if user is admin
CREATE OR REPLACE FUNCTION public.is_admin()
RETURNS BOOLEAN AS $$
BEGIN
RETURN 'admin' = ANY(public.get_user_roles());
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to check if user has specific role
CREATE OR REPLACE FUNCTION public.has_role(role_name TEXT)
RETURNS BOOLEAN AS $$
BEGIN
RETURN role_name = ANY(public.get_user_roles());
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Helper function to check if user can manage experiments
CREATE OR REPLACE FUNCTION public.can_manage_experiments()
RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1
FROM public.user_roles ur
JOIN public.roles r ON ur.role_id = r.id
WHERE ur.user_id = auth.uid()
AND r.name IN ('admin', 'conductor')
);
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- =============================================
-- 5. FUNCTIONS FOR OVERLAP PREVENTION
-- =============================================
-- Function to check for overlapping availabilities
CREATE OR REPLACE FUNCTION public.check_availability_overlap()
RETURNS TRIGGER AS $$
DECLARE
overlap_count INTEGER;
BEGIN
-- Check for overlapping availabilities for the same user
SELECT COUNT(*) INTO overlap_count
FROM public.conductor_availability
WHERE user_id = NEW.user_id
AND id != COALESCE(NEW.id, '00000000-0000-0000-0000-000000000000'::UUID)
AND status = 'active'
AND (
-- New availability starts during an existing one
(NEW.available_from >= available_from AND NEW.available_from < available_to) OR
-- New availability ends during an existing one
(NEW.available_to > available_from AND NEW.available_to <= available_to) OR
-- New availability completely contains an existing one
(NEW.available_from <= available_from AND NEW.available_to >= available_to) OR
-- Existing availability completely contains the new one
(available_from <= NEW.available_from AND available_to >= NEW.available_to)
);
IF overlap_count > 0 THEN
RAISE EXCEPTION 'Availability overlaps with existing availability for user %. Please adjust the time range or cancel the conflicting availability.', NEW.user_id;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Function to automatically adjust overlapping availabilities (alternative approach)
CREATE OR REPLACE FUNCTION public.adjust_overlapping_availability()
RETURNS TRIGGER AS $$
DECLARE
overlapping_record RECORD;
BEGIN
-- Find overlapping availabilities and adjust them
FOR overlapping_record IN
SELECT id, available_from, available_to
FROM public.conductor_availability
WHERE user_id = NEW.user_id
AND id != COALESCE(NEW.id, '00000000-0000-0000-0000-000000000000'::UUID)
AND status = 'active'
AND (
(NEW.available_from >= available_from AND NEW.available_from < available_to) OR
(NEW.available_to > available_from AND NEW.available_to <= available_to) OR
(NEW.available_from <= available_from AND NEW.available_to >= available_to) OR
(available_from <= NEW.available_from AND available_to >= NEW.available_to)
)
LOOP
-- Adjust the overlapping record to end where the new one starts
IF overlapping_record.available_from < NEW.available_from AND overlapping_record.available_to > NEW.available_from THEN
UPDATE public.conductor_availability
SET available_to = NEW.available_from,
updated_at = NOW()
WHERE id = overlapping_record.id;
END IF;
-- If the overlapping record starts after the new one, adjust it to start where the new one ends
IF overlapping_record.available_from < NEW.available_to AND overlapping_record.available_to > NEW.available_to THEN
UPDATE public.conductor_availability
SET available_from = NEW.available_to,
updated_at = NOW()
WHERE id = overlapping_record.id;
END IF;
-- If the overlapping record is completely contained within the new one, cancel it
IF overlapping_record.available_from >= NEW.available_from AND overlapping_record.available_to <= NEW.available_to THEN
UPDATE public.conductor_availability
SET status = 'cancelled',
updated_at = NOW()
WHERE id = overlapping_record.id;
END IF;
END LOOP;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- =============================================
-- 6. TRIGGERS
-- =============================================
-- Create trigger for updated_at on conductor_availability
CREATE TRIGGER set_updated_at_conductor_availability
BEFORE UPDATE ON public.conductor_availability
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- Create trigger for updated_at on experiment_phase_assignments
CREATE TRIGGER set_updated_at_experiment_phase_assignments
BEFORE UPDATE ON public.experiment_phase_assignments
FOR EACH ROW
EXECUTE FUNCTION public.handle_updated_at();
-- Create trigger to prevent overlapping availabilities (strict approach)
CREATE TRIGGER trigger_check_availability_overlap
BEFORE INSERT OR UPDATE ON public.conductor_availability
FOR EACH ROW
EXECUTE FUNCTION public.check_availability_overlap();
-- Alternative trigger to automatically adjust overlapping availabilities (uncomment if preferred)
-- CREATE TRIGGER trigger_adjust_overlapping_availability
-- BEFORE INSERT OR UPDATE ON public.conductor_availability
-- FOR EACH ROW
-- EXECUTE FUNCTION public.adjust_overlapping_availability();
-- =============================================
-- 6. HELPER FUNCTIONS
-- =============================================
-- Function to get available conductors for a specific time range
CREATE OR REPLACE FUNCTION public.get_available_conductors(
start_time TIMESTAMP WITH TIME ZONE,
end_time TIMESTAMP WITH TIME ZONE
)
RETURNS TABLE (
user_id UUID,
email TEXT,
available_from TIMESTAMP WITH TIME ZONE,
available_to TIMESTAMP WITH TIME ZONE
) AS $$
BEGIN
RETURN QUERY
SELECT
ca.user_id,
up.email,
ca.available_from,
ca.available_to
FROM public.conductor_availability ca
JOIN public.user_profiles up ON ca.user_id = up.id
JOIN public.user_roles ur ON up.id = ur.user_id
JOIN public.roles r ON ur.role_id = r.id
WHERE ca.status = 'active'
AND r.name = 'conductor'
AND ca.available_from <= start_time
AND ca.available_to >= end_time
ORDER BY up.email;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Function to check if a conductor is available for a specific time range
CREATE OR REPLACE FUNCTION public.is_conductor_available(
conductor_user_id UUID,
start_time TIMESTAMP WITH TIME ZONE,
end_time TIMESTAMP WITH TIME ZONE
)
RETURNS BOOLEAN AS $$
DECLARE
availability_count INTEGER;
BEGIN
SELECT COUNT(*) INTO availability_count
FROM public.conductor_availability
WHERE user_id = conductor_user_id
AND status = 'active'
AND available_from <= start_time
AND available_to >= end_time;
RETURN availability_count > 0;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- =============================================
-- 8. ROW LEVEL SECURITY (RLS)
-- =============================================
-- Enable RLS on new tables
ALTER TABLE public.conductor_availability ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.experiment_phase_assignments ENABLE ROW LEVEL SECURITY;
-- Conductor availability policies
CREATE POLICY "conductor_availability_select_policy" ON public.conductor_availability
FOR SELECT
TO authenticated
USING (
-- Users can view their own availability, admins can view all
user_id = auth.uid() OR public.is_admin()
);
CREATE POLICY "conductor_availability_insert_policy" ON public.conductor_availability
FOR INSERT
TO authenticated
WITH CHECK (
-- Users can create their own availability, admins can create for anyone
(user_id = auth.uid() AND created_by = auth.uid()) OR public.is_admin()
);
CREATE POLICY "conductor_availability_update_policy" ON public.conductor_availability
FOR UPDATE
TO authenticated
USING (
-- Users can update their own availability, admins can update any
user_id = auth.uid() OR public.is_admin()
)
WITH CHECK (
-- Users can update their own availability, admins can update any
user_id = auth.uid() OR public.is_admin()
);
CREATE POLICY "conductor_availability_delete_policy" ON public.conductor_availability
FOR DELETE
TO authenticated
USING (
-- Users can delete their own availability, admins can delete any
user_id = auth.uid() OR public.is_admin()
);
-- Experiment phase assignments policies
CREATE POLICY "experiment_phase_assignments_select_policy" ON public.experiment_phase_assignments
FOR SELECT
TO authenticated
USING (
-- Conductors can view their own assignments, admins can view all
conductor_id = auth.uid() OR public.is_admin()
);
CREATE POLICY "experiment_phase_assignments_insert_policy" ON public.experiment_phase_assignments
FOR INSERT
TO authenticated
WITH CHECK (
-- Only admins and conductors can create assignments
public.can_manage_experiments()
);
CREATE POLICY "experiment_phase_assignments_update_policy" ON public.experiment_phase_assignments
FOR UPDATE
TO authenticated
USING (
-- Conductors can update their own assignments, admins can update any
conductor_id = auth.uid() OR public.is_admin()
)
WITH CHECK (
-- Conductors can update their own assignments, admins can update any
conductor_id = auth.uid() OR public.is_admin()
);
CREATE POLICY "experiment_phase_assignments_delete_policy" ON public.experiment_phase_assignments
FOR DELETE
TO authenticated
USING (
-- Only admins can delete assignments
public.is_admin()
);
-- =============================================
-- 8. COMMENTS FOR DOCUMENTATION
-- =============================================
COMMENT ON TABLE public.conductor_availability IS 'Stores conductor availability windows for experiment scheduling';
COMMENT ON TABLE public.experiment_phase_assignments IS 'Assigns conductors to specific experiment repetition phases with scheduled times';
COMMENT ON COLUMN public.conductor_availability.available_from IS 'Start time of availability window';
COMMENT ON COLUMN public.conductor_availability.available_to IS 'End time of availability window';
COMMENT ON COLUMN public.conductor_availability.notes IS 'Optional notes about the availability period';
COMMENT ON COLUMN public.conductor_availability.status IS 'Status of the availability (active or cancelled)';
COMMENT ON COLUMN public.experiment_phase_assignments.phase_name IS 'Experiment phase being assigned (pre-soaking, air-drying, cracking, shelling)';
COMMENT ON COLUMN public.experiment_phase_assignments.scheduled_start_time IS 'Planned start time for the phase';
COMMENT ON COLUMN public.experiment_phase_assignments.scheduled_end_time IS 'Planned end time for the phase';
COMMENT ON COLUMN public.experiment_phase_assignments.status IS 'Current status of the assignment';
COMMENT ON COLUMN public.experiment_phase_assignments.notes IS 'Optional notes about the assignment';