From 9f669e7dffab9012ee20763f4238b8ae2115c887 Mon Sep 17 00:00:00 2001 From: salirezav Date: Wed, 29 Oct 2025 14:16:19 -0400 Subject: [PATCH] Enhance scheduling and drag-and-drop functionality in the Calendar component - Improved drag-and-drop experience for event scheduling with visual feedback and better cursor styles. - Added state management for tracking repetitions, including locked schedules and currently scheduling repetitions. - Implemented re-staggering logic to prevent overlap of scheduled events. - Enhanced event generation to include time points for soaking, airdrying, and cracking phases. - Updated the calendar to preserve and restore scroll position during event updates. - Refactored event handling to ensure smooth interaction and improved user experience. --- .../src/components/CalendarStyles.css | 46 ++ .../src/components/Scheduling.tsx | 504 ++++++++++++++---- .../supabase/.temp/cli-latest | 2 +- .../supabase/config.toml | 3 +- ...0101000003_experiments_and_repetitions.sql | 11 +- .../20250101000004_data_entry_tables.sql | 84 +-- ...0926_fix_experiment_repetitions_schema.sql | 111 ---- .../20250927_fix_phase_tables_fk.sql | 235 -------- .../seed_04_phase2_jc_experiments_old.sql | 26 +- .../seed_04_phase2_jc_experiments_updated.sql | 43 +- .../seed_05_meyer_experiments_old.sql | 26 +- .../seed_05_meyer_experiments_updated.sql | 43 +- 12 files changed, 560 insertions(+), 574 deletions(-) delete mode 100644 management-dashboard-web-app/supabase/migrations/20250926_fix_experiment_repetitions_schema.sql delete mode 100644 management-dashboard-web-app/supabase/migrations/20250927_fix_phase_tables_fk.sql diff --git a/management-dashboard-web-app/src/components/CalendarStyles.css b/management-dashboard-web-app/src/components/CalendarStyles.css index 4863a4c..329394d 100644 --- a/management-dashboard-web-app/src/components/CalendarStyles.css +++ b/management-dashboard-web-app/src/components/CalendarStyles.css @@ -186,6 +186,52 @@ color: #f9fafb; } +/* Drag and drop improvements */ +.rbc-event { + cursor: grab !important; + user-select: none; +} + +.rbc-event:active { + cursor: grabbing !important; + transform: scale(1.05); + z-index: 1000 !important; + box-shadow: 0 4px 8px rgba(0, 0, 0, 0.3) !important; +} + +/* Improve event spacing and visibility */ +.rbc-event-content { + pointer-events: none; +} + +/* Better visual feedback for dragging */ +.rbc-addons-dnd-dragging { + opacity: 0.8; + transform: rotate(2deg); + z-index: 1000 !important; +} + +.rbc-addons-dnd-drag-preview { + background: rgba(255, 255, 255, 0.9) !important; + border: 2px dashed #3b82f6 !important; + border-radius: 8px !important; + padding: 8px 12px !important; + font-weight: bold !important; + color: #1f2937 !important; + box-shadow: 0 4px 12px rgba(0, 0, 0, 0.3) !important; +} + +/* Improve event hover states */ +.rbc-event:hover { + transform: translateY(-1px); + box-shadow: 0 4px 8px rgba(0, 0, 0, 0.2) !important; +} + +/* Better spacing between events */ +.rbc-time-slot { + min-height: 24px; +} + /* Responsive adjustments */ @media (max-width: 768px) { .rbc-toolbar { diff --git a/management-dashboard-web-app/src/components/Scheduling.tsx b/management-dashboard-web-app/src/components/Scheduling.tsx index 6211bcb..8b622a7 100644 --- a/management-dashboard-web-app/src/components/Scheduling.tsx +++ b/management-dashboard-web-app/src/components/Scheduling.tsx @@ -1,4 +1,4 @@ -import { useEffect, useState } from 'react' +import { useEffect, useState, useMemo, useCallback, useRef } from 'react' // @ts-ignore - react-big-calendar types not available import { Calendar, momentLocalizer, Views } from 'react-big-calendar' // @ts-ignore - react-big-calendar dragAndDrop types not available @@ -327,9 +327,20 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } crackingStart: Date | null }>>({}) + // Track repetitions that have been dropped/moved and should show time points + const [repetitionsWithTimes, setRepetitionsWithTimes] = useState>(new Set()) + // Track which repetitions are locked (prevent dragging) + const [lockedSchedules, setLockedSchedules] = useState>(new Set()) + // Track which repetitions are currently being scheduled + const [schedulingRepetitions, setSchedulingRepetitions] = useState>(new Set()) + // Visual style for repetition markers const [markerStyle, setMarkerStyle] = useState<'circles' | 'dots' | 'icons' | 'lines'>('lines') + // Ref for calendar container to preserve scroll position + const calendarRef = useRef(null) + const scrollPositionRef = useRef<{ scrollTop: number; scrollLeft: number } | null>(null) + useEffect(() => { const load = async () => { try { @@ -503,10 +514,33 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } delete newScheduled[repId] return newScheduled }) + // Clear all related state when unchecked + setRepetitionsWithTimes(prev => { + const next = new Set(prev) + next.delete(repId) + return next + }) + setLockedSchedules(prev => { + const next = new Set(prev) + next.delete(repId) + return next + }) + setSchedulingRepetitions(prev => { + const next = new Set(prev) + next.delete(repId) + return next + }) + // Re-stagger remaining repetitions + const remainingIds = Array.from(next).filter(id => id !== repId) + if (remainingIds.length > 0) { + reStaggerRepetitions(remainingIds) + } } else { next.add(repId) // Auto-spawn when checked spawnSingleRepetition(repId) + // Re-stagger all existing repetitions to prevent overlap + reStaggerRepetitions([...next, repId]) } return next }) @@ -570,6 +604,54 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } } } + // Re-stagger all repetitions to prevent overlap + const reStaggerRepetitions = (repIds: string[]) => { + const tomorrow = new Date() + tomorrow.setDate(tomorrow.getDate() + 1) + tomorrow.setHours(9, 0, 0, 0) + + setScheduledRepetitions(prev => { + const newScheduled = { ...prev } + + repIds.forEach((repId, index) => { + if (newScheduled[repId]) { + const staggerMinutes = index * 15 // 15 minutes between each repetition + const baseTime = new Date(tomorrow.getTime() + (staggerMinutes * 60000)) + + // Find the experiment for this repetition + let experimentId = '' + for (const [expId, reps] of Object.entries(repetitionsByExperiment)) { + if (reps.find(r => r.id === repId)) { + experimentId = expId + break + } + } + + if (experimentId) { + const experiment = Object.values(experimentsByPhase).flat().find(e => e.id === experimentId) + const soaking = soakingByExperiment[experimentId] + const airdrying = airdryingByExperiment[experimentId] + + if (experiment && soaking && airdrying) { + const soakingStart = new Date(baseTime) + const airdryingStart = new Date(soakingStart.getTime() + (soaking.soaking_duration_minutes * 60000)) + const crackingStart = new Date(airdryingStart.getTime() + (airdrying.duration_minutes * 60000)) + + newScheduled[repId] = { + ...newScheduled[repId], + soakingStart, + airdryingStart, + crackingStart + } + } + } + } + }) + + return newScheduled + }) + } + // Spawn a single repetition in calendar const spawnSingleRepetition = (repId: string) => { const tomorrow = new Date() @@ -591,7 +673,12 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } const airdrying = airdryingByExperiment[experimentId] if (experiment && soaking && airdrying) { - const soakingStart = new Date(tomorrow) + // Stagger the positioning to avoid overlap when multiple repetitions are selected + const selectedReps = Array.from(selectedRepetitionIds) + const repIndex = selectedReps.indexOf(repId) + const staggerMinutes = repIndex * 15 // 15 minutes between each repetition's time points + + const soakingStart = new Date(tomorrow.getTime() + (staggerMinutes * 60000)) const airdryingStart = new Date(soakingStart.getTime() + (soaking.soaking_duration_minutes * 60000)) const crackingStart = new Date(airdryingStart.getTime() + (airdrying.duration_minutes * 60000)) @@ -623,35 +710,47 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } let newScheduled = { ...prev } + const clampToReasonableHours = (d: Date) => { + const min = new Date(d) + min.setHours(5, 0, 0, 0) + const max = new Date(d) + max.setHours(23, 0, 0, 0) + const t = d.getTime() + return new Date(Math.min(Math.max(t, min.getTime()), max.getTime())) + } + if (phase === 'soaking') { - const airdryingStart = new Date(newTime.getTime() + (soaking.soaking_duration_minutes * 60000)) - const crackingStart = new Date(airdryingStart.getTime() + (airdrying.duration_minutes * 60000)) + const soakingStart = clampToReasonableHours(newTime) + const airdryingStart = clampToReasonableHours(new Date(soakingStart.getTime() + (soaking.soaking_duration_minutes * 60000))) + const crackingStart = clampToReasonableHours(new Date(airdryingStart.getTime() + (airdrying.duration_minutes * 60000))) newScheduled[repId] = { ...current, - soakingStart: newTime, + soakingStart, airdryingStart, crackingStart } } else if (phase === 'airdrying') { - const soakingStart = new Date(newTime.getTime() - (soaking.soaking_duration_minutes * 60000)) - const crackingStart = new Date(newTime.getTime() + (airdrying.duration_minutes * 60000)) - - newScheduled[repId] = { - ...current, - soakingStart, - airdryingStart: newTime, - crackingStart - } - } else if (phase === 'cracking') { - const airdryingStart = new Date(newTime.getTime() - (airdrying.duration_minutes * 60000)) - const soakingStart = new Date(airdryingStart.getTime() - (soaking.soaking_duration_minutes * 60000)) + const airdryingStart = clampToReasonableHours(newTime) + const soakingStart = clampToReasonableHours(new Date(airdryingStart.getTime() - (soaking.soaking_duration_minutes * 60000))) + const crackingStart = clampToReasonableHours(new Date(airdryingStart.getTime() + (airdrying.duration_minutes * 60000))) newScheduled[repId] = { ...current, soakingStart, airdryingStart, - crackingStart: newTime + crackingStart + } + } else if (phase === 'cracking') { + const crackingStart = clampToReasonableHours(newTime) + const airdryingStart = clampToReasonableHours(new Date(crackingStart.getTime() - (airdrying.duration_minutes * 60000))) + const soakingStart = clampToReasonableHours(new Date(airdryingStart.getTime() - (soaking.soaking_duration_minutes * 60000))) + + newScheduled[repId] = { + ...current, + soakingStart, + airdryingStart, + crackingStart } } @@ -659,8 +758,8 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } }) } - // Generate calendar events for scheduled repetitions - const generateRepetitionEvents = (): CalendarEvent[] => { + // Generate calendar events for scheduled repetitions (memoized) + const generateRepetitionEvents = useCallback((): CalendarEvent[] => { const events: CalendarEvent[] = [] Object.values(scheduledRepetitions).forEach(scheduled => { @@ -673,7 +772,7 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } id: `${scheduled.repetitionId}-soaking`, title: `💧 Soaking - Exp ${experiment.experiment_number} Rep ${repetition.repetition_number}`, start: scheduled.soakingStart, - end: new Date(scheduled.soakingStart.getTime() + 30 * 60000), // 30 minute duration for visibility + end: new Date(scheduled.soakingStart.getTime() + 15 * 60000), // 15 minute duration for better visibility resource: 'soaking' }) @@ -683,7 +782,7 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } id: `${scheduled.repetitionId}-airdrying`, title: `🌬️ Airdrying - Exp ${experiment.experiment_number} Rep ${repetition.repetition_number}`, start: scheduled.airdryingStart, - end: new Date(scheduled.airdryingStart.getTime() + 30 * 60000), + end: new Date(scheduled.airdryingStart.getTime() + 15 * 60000), // 15 minute duration for better visibility resource: 'airdrying' }) } @@ -694,7 +793,7 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } id: `${scheduled.repetitionId}-cracking`, title: `⚡ Cracking - Exp ${experiment.experiment_number} Rep ${repetition.repetition_number}`, start: scheduled.crackingStart, - end: new Date(scheduled.crackingStart.getTime() + 30 * 60000), + end: new Date(scheduled.crackingStart.getTime() + 15 * 60000), // 15 minute duration for better visibility resource: 'cracking' }) } @@ -702,8 +801,203 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } }) return events + }, [scheduledRepetitions, experimentsByPhase, repetitionsByExperiment]) + + // Memoize the calendar events to prevent unnecessary re-renders + const calendarEvents = useMemo(() => generateRepetitionEvents(), [generateRepetitionEvents]) + + // Functions to preserve and restore scroll position + const preserveScrollPosition = useCallback(() => { + if (calendarRef.current) { + const scrollContainer = calendarRef.current.querySelector('.rbc-time-content') as HTMLElement + if (scrollContainer) { + scrollPositionRef.current = { + scrollTop: scrollContainer.scrollTop, + scrollLeft: scrollContainer.scrollLeft + } + } + } + }, []) + + const restoreScrollPosition = useCallback(() => { + if (calendarRef.current && scrollPositionRef.current) { + const scrollContainer = calendarRef.current.querySelector('.rbc-time-content') as HTMLElement + if (scrollContainer) { + scrollContainer.scrollTop = scrollPositionRef.current.scrollTop + scrollContainer.scrollLeft = scrollPositionRef.current.scrollLeft + } + } + }, []) + + // Helper functions for scheduling + const formatTime = (date: Date | null) => { + if (!date) return 'Not set' + return moment(date).format('MMM D, h:mm A') } + const toggleScheduleLock = (repId: string) => { + setLockedSchedules(prev => { + const next = new Set(prev) + if (next.has(repId)) { + next.delete(repId) + } else { + next.add(repId) + } + return next + }) + } + + const draggableAccessor = useCallback((event: any) => { + // Only make repetition markers draggable, not availability events + const resource = event.resource as string + if (resource === 'soaking' || resource === 'airdrying' || resource === 'cracking') { + // Check if the repetition is locked + const eventId = event.id as string + const repId = eventId.split('-')[0] + const isLocked = lockedSchedules.has(repId) + return !isLocked + } + return false + }, [lockedSchedules]) + + const eventPropGetter = useCallback((event: any) => { + const resource = event.resource as string + + // Styling for repetition markers (foreground events) + if (resource === 'soaking' || resource === 'airdrying' || resource === 'cracking') { + const eventId = event.id as string + const repId = eventId.split('-')[0] + const isLocked = lockedSchedules.has(repId) + + const colors = { + soaking: '#3b82f6', // blue + airdrying: '#10b981', // green + cracking: '#f59e0b' // orange + } + const color = colors[resource as keyof typeof colors] || '#6b7280' + + return { + style: { + backgroundColor: isLocked ? '#9ca3af' : color, // gray if locked + borderColor: isLocked ? color : color, // border takes original color when locked + color: 'white', + borderRadius: '8px', + border: '2px solid', + height: '40px', + minHeight: '40px', + fontSize: '12px', + padding: '8px 12px', + display: 'flex', + flexDirection: 'row', + alignItems: 'center', + justifyContent: 'flex-start', + fontWeight: 'bold', + zIndex: 10, + position: 'relative', + lineHeight: '1.4', + textShadow: '1px 1px 2px rgba(0,0,0,0.7)', + gap: '8px', + overflow: 'hidden', + textOverflow: 'ellipsis', + whiteSpace: 'nowrap', + cursor: isLocked ? 'not-allowed' : 'grab', + boxShadow: isLocked ? '0 1px 2px rgba(0,0,0,0.1)' : '0 2px 4px rgba(0,0,0,0.2)', + transition: 'all 0.2s ease', + opacity: isLocked ? 0.7 : 1 + } + } + } + + // Default styling for other events + return {} + }, [lockedSchedules]) + + const scheduleRepetition = async (repId: string, experimentId: string) => { + setSchedulingRepetitions(prev => new Set(prev).add(repId)) + + try { + const scheduled = scheduledRepetitions[repId] + if (!scheduled) throw new Error('No scheduled times found') + + const { soakingStart, airdryingStart, crackingStart } = scheduled + if (!soakingStart || !airdryingStart || !crackingStart) { + throw new Error('All time points must be set') + } + + const soaking = soakingByExperiment[experimentId] + const airdrying = airdryingByExperiment[experimentId] + + if (!soaking || !airdrying) throw new Error('Phase data not found') + + // Update repetition scheduled_date (earliest time point) + await repetitionManagement.updateRepetition(repId, { + scheduled_date: soakingStart.toISOString() + }) + + // Create/update soaking record with repetition_id + await phaseManagement.createSoaking({ + experiment_id: experimentId, + repetition_id: repId, + scheduled_start_time: soakingStart.toISOString(), + soaking_duration_minutes: soaking.soaking_duration_minutes + }) + + // Create/update airdrying record with repetition_id + await phaseManagement.createAirdrying({ + experiment_id: experimentId, + repetition_id: repId, + scheduled_start_time: airdryingStart.toISOString(), + duration_minutes: airdrying.duration_minutes + }) + + // Create/update cracking record with repetition_id + // Note: cracking requires machine_type_id - need to get from experiment phase + const experiment = Object.values(experimentsByPhase).flat().find(e => e.id === experimentId) + const phase = phases.find(p => p.id === experiment?.phase_id) + + if (phase?.cracking_machine_type_id) { + await phaseManagement.createCracking({ + experiment_id: experimentId, + repetition_id: repId, + machine_type_id: phase.cracking_machine_type_id, + scheduled_start_time: crackingStart.toISOString() + }) + } + + // Update local state to reflect scheduling + setRepetitionsByExperiment(prev => ({ + ...prev, + [experimentId]: prev[experimentId]?.map(r => + r.id === repId + ? { ...r, scheduled_date: soakingStart.toISOString() } + : r + ) || [] + })) + + } catch (error: any) { + setError(error?.message || 'Failed to schedule repetition') + } finally { + setSchedulingRepetitions(prev => { + const next = new Set(prev) + next.delete(repId) + return next + }) + } + } + + // Restore scroll position after scheduledRepetitions changes + useEffect(() => { + if (scrollPositionRef.current) { + // Use a longer delay to ensure the calendar has fully re-rendered + const timeoutId = setTimeout(() => { + restoreScrollPosition() + }, 50) + + return () => clearTimeout(timeoutId) + } + }, [scheduledRepetitions, restoreScrollPosition]) + + return (
@@ -874,19 +1168,65 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } )}
-
+
{reps.map(rep => { const checked = selectedRepetitionIds.has(rep.id) + const hasTimes = repetitionsWithTimes.has(rep.id) + const scheduled = scheduledRepetitions[rep.id] + const isLocked = lockedSchedules.has(rep.id) + const isScheduling = schedulingRepetitions.has(rep.id) + return ( - +
+ {/* Checkbox row */} + + + {/* Time points (shown only if has been dropped/moved) */} + {hasTimes && scheduled && ( +
+
+ 💧 + Soaking: {formatTime(scheduled.soakingStart)} +
+
+ 🌬️ + Airdrying: {formatTime(scheduled.airdryingStart)} +
+
+ + Cracking: {formatTime(scheduled.crackingStart)} +
+ + {/* Lock checkbox and Schedule button */} +
+ + +
+
+ )} +
) })} {reps.length === 0 && !isCreating && ( @@ -957,11 +1297,11 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void }
-
+
void } onNavigate={setCurrentDate} views={[Views.WEEK, Views.DAY]} dayLayoutAlgorithm="no-overlap" - draggableAccessor={(event: any) => { - // Only make repetition markers draggable, not availability events - const resource = event.resource as string - return resource === 'soaking' || resource === 'airdrying' || resource === 'cracking' - }} + draggableAccessor={draggableAccessor} onEventDrop={({ event, start }: { event: any, start: Date }) => { + // Preserve scroll position before updating + preserveScrollPosition() + // Handle dragging repetition markers const eventId = event.id as string + // Clamp to reasonable working hours (5AM to 11PM) to prevent extreme times + const clampToReasonableHours = (d: Date) => { + const min = new Date(d) + min.setHours(5, 0, 0, 0) + const max = new Date(d) + max.setHours(23, 0, 0, 0) + const t = d.getTime() + return new Date(Math.min(Math.max(t, min.getTime()), max.getTime())) + } + const clampedStart = clampToReasonableHours(start) + + let repId = '' if (eventId.includes('-soaking')) { - const repId = eventId.replace('-soaking', '') - updatePhaseTiming(repId, 'soaking', start) + repId = eventId.replace('-soaking', '') + updatePhaseTiming(repId, 'soaking', clampedStart) } else if (eventId.includes('-airdrying')) { - const repId = eventId.replace('-airdrying', '') - updatePhaseTiming(repId, 'airdrying', start) + repId = eventId.replace('-airdrying', '') + updatePhaseTiming(repId, 'airdrying', clampedStart) } else if (eventId.includes('-cracking')) { - const repId = eventId.replace('-cracking', '') - updatePhaseTiming(repId, 'cracking', start) - } - }} - eventPropGetter={(event: any) => { - const resource = event.resource as string - - // Styling for repetition markers (foreground events) - if (resource === 'soaking' || resource === 'airdrying' || resource === 'cracking') { - const colors = { - soaking: '#3b82f6', // blue - airdrying: '#10b981', // green - cracking: '#f59e0b' // orange - } - const color = colors[resource as keyof typeof colors] || '#6b7280' - - // Get step names and icons - const stepInfo = { - soaking: { name: 'Soaking', icon: '💧' }, - airdrying: { name: 'Airdrying', icon: '🌬️' }, - cracking: { name: 'Cracking', icon: '⚡' } - } - const step = stepInfo[resource as keyof typeof stepInfo] - - return { - style: { - backgroundColor: color, - borderColor: color, - color: 'white', - borderRadius: '6px', - border: 'none', - height: '36px', - minHeight: '36px', - fontSize: '13px', - padding: '6px 10px', - display: 'flex', - flexDirection: 'row', - alignItems: 'center', - justifyContent: 'flex-start', - fontWeight: 'bold', - zIndex: 10, - position: 'relative', - lineHeight: '1.4', - textShadow: '1px 1px 2px rgba(0,0,0,0.7)', - gap: '6px', - overflow: 'hidden', - textOverflow: 'ellipsis', - whiteSpace: 'nowrap' - } - } + repId = eventId.replace('-cracking', '') + updatePhaseTiming(repId, 'cracking', clampedStart) } - // Default styling for other events - return {} + // Add repetition to show time points + if (repId) { + setRepetitionsWithTimes(prev => new Set(prev).add(repId)) + } + + // Restore scroll position after a brief delay to allow for re-render + setTimeout(() => { + restoreScrollPosition() + }, 10) }} + eventPropGetter={eventPropGetter} backgroundEventPropGetter={(event: any) => { // Styling for background events (conductor availability) const conductorId = event.resource @@ -1074,6 +1385,7 @@ function ScheduleExperiment({ user, onBack }: { user: User; onBack: () => void } />
+
diff --git a/management-dashboard-web-app/supabase/.temp/cli-latest b/management-dashboard-web-app/supabase/.temp/cli-latest index 2fdeb23..65f2e19 100755 --- a/management-dashboard-web-app/supabase/.temp/cli-latest +++ b/management-dashboard-web-app/supabase/.temp/cli-latest @@ -1 +1 @@ -v2.45.5 \ No newline at end of file +v2.54.10 \ No newline at end of file diff --git a/management-dashboard-web-app/supabase/config.toml b/management-dashboard-web-app/supabase/config.toml index d1e1c0c..33dbfc2 100755 --- a/management-dashboard-web-app/supabase/config.toml +++ b/management-dashboard-web-app/supabase/config.toml @@ -57,7 +57,8 @@ schema_paths = [] enabled = true # Specifies an ordered list of seed files to load during db reset. # Supports glob patterns relative to supabase directory: "./seeds/*.sql" -sql_paths = ["./seed_01_users.sql", "./seed_04_phase2_jc_experiments.sql", "./seed_05_meyer_experiments.sql"] +sql_paths = ["./seed_01_users.sql"] +# , "./seed_04_phase2_jc_experiments.sql", "./seed_05_meyer_experiments.sql"] [db.network_restrictions] # Enable management of network restrictions. diff --git a/management-dashboard-web-app/supabase/migrations/20250101000003_experiments_and_repetitions.sql b/management-dashboard-web-app/supabase/migrations/20250101000003_experiments_and_repetitions.sql index f9bd339..6f67de6 100644 --- a/management-dashboard-web-app/supabase/migrations/20250101000003_experiments_and_repetitions.sql +++ b/management-dashboard-web-app/supabase/migrations/20250101000003_experiments_and_repetitions.sql @@ -29,20 +29,15 @@ CREATE TABLE IF NOT EXISTS public.experiments ( -- Create experiment repetitions table CREATE TABLE IF NOT EXISTS public.experiment_repetitions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - experiment_number INTEGER NOT NULL, - experiment_phase_id UUID NOT NULL, + experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_number INTEGER NOT NULL CHECK (repetition_number > 0), status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'in_progress', 'completed', 'cancelled')), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by UUID NOT NULL REFERENCES public.user_profiles(id), - -- Foreign key to experiments using composite key - FOREIGN KEY (experiment_number, experiment_phase_id) - REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE, - -- Ensure unique repetition numbers per experiment - UNIQUE(experiment_number, experiment_phase_id, repetition_number) + UNIQUE(experiment_id, repetition_number) ); -- ============================================= @@ -52,7 +47,7 @@ CREATE TABLE IF NOT EXISTS public.experiment_repetitions ( CREATE INDEX IF NOT EXISTS idx_experiments_phase_id ON public.experiments(phase_id); CREATE INDEX IF NOT EXISTS idx_experiments_experiment_number ON public.experiments(experiment_number); CREATE INDEX IF NOT EXISTS idx_experiments_created_by ON public.experiments(created_by); -CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_composite ON public.experiment_repetitions(experiment_number, experiment_phase_id); +CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_id ON public.experiment_repetitions(experiment_id); CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_created_by ON public.experiment_repetitions(created_by); -- ============================================= diff --git a/management-dashboard-web-app/supabase/migrations/20250101000004_data_entry_tables.sql b/management-dashboard-web-app/supabase/migrations/20250101000004_data_entry_tables.sql index 64a6c80..e439c0a 100644 --- a/management-dashboard-web-app/supabase/migrations/20250101000004_data_entry_tables.sql +++ b/management-dashboard-web-app/supabase/migrations/20250101000004_data_entry_tables.sql @@ -8,8 +8,7 @@ -- Create soaking table CREATE TABLE IF NOT EXISTS public.soaking ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - experiment_number INTEGER NOT NULL, - experiment_phase_id UUID NOT NULL, + experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE, scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_start_time TIMESTAMP WITH TIME ZONE, @@ -20,12 +19,8 @@ CREATE TABLE IF NOT EXISTS public.soaking ( updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by UUID NOT NULL REFERENCES public.user_profiles(id), - -- Foreign key to experiments using composite key - FOREIGN KEY (experiment_number, experiment_phase_id) - REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE, - -- Ensure only one soaking per experiment or repetition - CONSTRAINT unique_soaking_per_experiment UNIQUE (experiment_number, experiment_phase_id), + CONSTRAINT unique_soaking_per_experiment UNIQUE (experiment_id), CONSTRAINT unique_soaking_per_repetition UNIQUE (repetition_id) ); @@ -36,8 +31,7 @@ CREATE TABLE IF NOT EXISTS public.soaking ( -- Create airdrying table CREATE TABLE IF NOT EXISTS public.airdrying ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - experiment_number INTEGER NOT NULL, - experiment_phase_id UUID NOT NULL, + experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE, scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_start_time TIMESTAMP WITH TIME ZONE, @@ -48,12 +42,8 @@ CREATE TABLE IF NOT EXISTS public.airdrying ( updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by UUID NOT NULL REFERENCES public.user_profiles(id), - -- Foreign key to experiments using composite key - FOREIGN KEY (experiment_number, experiment_phase_id) - REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE, - -- Ensure only one airdrying per experiment or repetition - CONSTRAINT unique_airdrying_per_experiment UNIQUE (experiment_number, experiment_phase_id), + CONSTRAINT unique_airdrying_per_experiment UNIQUE (experiment_id), CONSTRAINT unique_airdrying_per_repetition UNIQUE (repetition_id) ); @@ -64,10 +54,11 @@ CREATE TABLE IF NOT EXISTS public.airdrying ( -- Create cracking table CREATE TABLE IF NOT EXISTS public.cracking ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - experiment_number INTEGER NOT NULL, - experiment_phase_id UUID NOT NULL, + experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE, machine_type_id UUID NOT NULL REFERENCES public.machine_types(id), + jc_cracker_parameters_id UUID REFERENCES public.jc_cracker_parameters(id) ON DELETE SET NULL, + meyer_cracker_parameters_id UUID REFERENCES public.meyer_cracker_parameters(id) ON DELETE SET NULL, scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_start_time TIMESTAMP WITH TIME ZONE, actual_end_time TIMESTAMP WITH TIME ZONE, @@ -75,13 +66,14 @@ CREATE TABLE IF NOT EXISTS public.cracking ( updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by UUID NOT NULL REFERENCES public.user_profiles(id), - -- Foreign key to experiments using composite key - FOREIGN KEY (experiment_number, experiment_phase_id) - REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE, - -- Ensure only one cracking per experiment or repetition - CONSTRAINT unique_cracking_per_experiment UNIQUE (experiment_number, experiment_phase_id), - CONSTRAINT unique_cracking_per_repetition UNIQUE (repetition_id) + CONSTRAINT unique_cracking_per_experiment UNIQUE (experiment_id), + CONSTRAINT unique_cracking_per_repetition UNIQUE (repetition_id), + -- Ensure exactly one cracker parameter set is specified + CONSTRAINT check_exactly_one_cracker_params CHECK ( + (jc_cracker_parameters_id IS NOT NULL AND meyer_cracker_parameters_id IS NULL) OR + (jc_cracker_parameters_id IS NULL AND meyer_cracker_parameters_id IS NOT NULL) + ) ); -- ============================================= @@ -91,8 +83,7 @@ CREATE TABLE IF NOT EXISTS public.cracking ( -- Create shelling table CREATE TABLE IF NOT EXISTS public.shelling ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - experiment_number INTEGER NOT NULL, - experiment_phase_id UUID NOT NULL, + experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE, scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_start_time TIMESTAMP WITH TIME ZONE, @@ -101,12 +92,8 @@ CREATE TABLE IF NOT EXISTS public.shelling ( updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by UUID NOT NULL REFERENCES public.user_profiles(id), - -- Foreign key to experiments using composite key - FOREIGN KEY (experiment_number, experiment_phase_id) - REFERENCES public.experiments(experiment_number, phase_id) ON DELETE CASCADE, - -- Ensure only one shelling per experiment or repetition - CONSTRAINT unique_shelling_per_experiment UNIQUE (experiment_number, experiment_phase_id), + CONSTRAINT unique_shelling_per_experiment UNIQUE (experiment_id), CONSTRAINT unique_shelling_per_repetition UNIQUE (repetition_id) ); @@ -117,52 +104,39 @@ CREATE TABLE IF NOT EXISTS public.shelling ( -- Create JC Cracker parameters table CREATE TABLE IF NOT EXISTS public.jc_cracker_parameters ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - cracking_id UUID NOT NULL REFERENCES public.cracking(id) ON DELETE CASCADE, plate_contact_frequency_hz DOUBLE PRECISION NOT NULL CHECK (plate_contact_frequency_hz > 0), throughput_rate_pecans_sec DOUBLE PRECISION NOT NULL CHECK (throughput_rate_pecans_sec > 0), crush_amount_in DOUBLE PRECISION NOT NULL CHECK (crush_amount_in >= 0), entry_exit_height_diff_in DOUBLE PRECISION NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), - updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), - - -- Ensure only one parameter set per cracking - CONSTRAINT unique_jc_params_per_cracking UNIQUE (cracking_id) + updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Create Meyer Cracker parameters table CREATE TABLE IF NOT EXISTS public.meyer_cracker_parameters ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), - cracking_id UUID NOT NULL REFERENCES public.cracking(id) ON DELETE CASCADE, motor_speed_hz DOUBLE PRECISION NOT NULL CHECK (motor_speed_hz > 0), jig_displacement_inches DOUBLE PRECISION NOT NULL, spring_stiffness_nm DOUBLE PRECISION NOT NULL CHECK (spring_stiffness_nm > 0), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), - updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), - - -- Ensure only one parameter set per cracking - CONSTRAINT unique_meyer_params_per_cracking UNIQUE (cracking_id) + updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- ============================================= --- 6. ADD FOREIGN KEY CONSTRAINTS TO EXPERIMENTS +-- 6. EXPERIMENTS TABLE DOES NOT NEED FOREIGN KEYS TO PHASE TABLES -- ============================================= - --- Add foreign key constraints to experiments table for phase associations -ALTER TABLE public.experiments -ADD COLUMN IF NOT EXISTS soaking_id UUID REFERENCES public.soaking(id) ON DELETE SET NULL, -ADD COLUMN IF NOT EXISTS airdrying_id UUID REFERENCES public.airdrying(id) ON DELETE SET NULL, -ADD COLUMN IF NOT EXISTS cracking_id UUID REFERENCES public.cracking(id) ON DELETE SET NULL, -ADD COLUMN IF NOT EXISTS shelling_id UUID REFERENCES public.shelling(id) ON DELETE SET NULL; +-- Phase tables reference experiments via experiment_id +-- Experiments inherit phase configuration from experiment_phases via phase_id -- ============================================= -- 7. INDEXES FOR PERFORMANCE -- ============================================= --- Create composite indexes for phase tables -CREATE INDEX IF NOT EXISTS idx_soaking_experiment_composite ON public.soaking(experiment_number, experiment_phase_id); -CREATE INDEX IF NOT EXISTS idx_airdrying_experiment_composite ON public.airdrying(experiment_number, experiment_phase_id); -CREATE INDEX IF NOT EXISTS idx_cracking_experiment_composite ON public.cracking(experiment_number, experiment_phase_id); -CREATE INDEX IF NOT EXISTS idx_shelling_experiment_composite ON public.shelling(experiment_number, experiment_phase_id); +-- Create indexes for experiment_id references +CREATE INDEX IF NOT EXISTS idx_soaking_experiment_id ON public.soaking(experiment_id); +CREATE INDEX IF NOT EXISTS idx_airdrying_experiment_id ON public.airdrying(experiment_id); +CREATE INDEX IF NOT EXISTS idx_cracking_experiment_id ON public.cracking(experiment_id); +CREATE INDEX IF NOT EXISTS idx_shelling_experiment_id ON public.shelling(experiment_id); -- Create indexes for repetition references CREATE INDEX IF NOT EXISTS idx_soaking_repetition_id ON public.soaking(repetition_id); @@ -224,8 +198,7 @@ BEGIN IF NEW.scheduled_start_time IS NULL THEN SELECT s.scheduled_end_time INTO NEW.scheduled_start_time FROM public.soaking s - WHERE s.experiment_number = NEW.experiment_number - AND s.experiment_phase_id = NEW.experiment_phase_id + WHERE s.experiment_id = NEW.experiment_id LIMIT 1; END IF; RETURN NEW; @@ -248,8 +221,7 @@ BEGIN IF NEW.scheduled_start_time IS NULL THEN SELECT a.scheduled_end_time INTO NEW.scheduled_start_time FROM public.airdrying a - WHERE a.experiment_number = NEW.experiment_number - AND a.experiment_phase_id = NEW.experiment_phase_id + WHERE a.experiment_id = NEW.experiment_id LIMIT 1; END IF; RETURN NEW; diff --git a/management-dashboard-web-app/supabase/migrations/20250926_fix_experiment_repetitions_schema.sql b/management-dashboard-web-app/supabase/migrations/20250926_fix_experiment_repetitions_schema.sql deleted file mode 100644 index 31802c0..0000000 --- a/management-dashboard-web-app/supabase/migrations/20250926_fix_experiment_repetitions_schema.sql +++ /dev/null @@ -1,111 +0,0 @@ --- Align experiment_repetitions schema with application expectations --- Adds experiment_id and scheduled_date, maintains existing data, and updates constraints - --- 1) Add columns if missing and remove NOT NULL constraints from old columns -DO $$ -BEGIN - IF NOT EXISTS ( - SELECT 1 FROM information_schema.columns - WHERE table_schema = 'public' AND table_name = 'experiment_repetitions' AND column_name = 'experiment_id' - ) THEN - ALTER TABLE public.experiment_repetitions - ADD COLUMN experiment_id UUID; - END IF; - - IF NOT EXISTS ( - SELECT 1 FROM information_schema.columns - WHERE table_schema = 'public' AND table_name = 'experiment_repetitions' AND column_name = 'scheduled_date' - ) THEN - ALTER TABLE public.experiment_repetitions - ADD COLUMN scheduled_date TIMESTAMPTZ NULL; - END IF; - - IF NOT EXISTS ( - SELECT 1 FROM information_schema.columns - WHERE table_schema = 'public' AND table_name = 'experiment_repetitions' AND column_name = 'completion_status' - ) THEN - ALTER TABLE public.experiment_repetitions - ADD COLUMN completion_status BOOLEAN NOT NULL DEFAULT false; - END IF; - - IF NOT EXISTS ( - SELECT 1 FROM information_schema.columns - WHERE table_schema = 'public' AND table_name = 'experiment_repetitions' AND column_name = 'is_locked' - ) THEN - ALTER TABLE public.experiment_repetitions - ADD COLUMN is_locked BOOLEAN NOT NULL DEFAULT false, - ADD COLUMN locked_at TIMESTAMPTZ NULL, - ADD COLUMN locked_by UUID NULL REFERENCES public.user_profiles(id); - END IF; - - -- Remove NOT NULL constraints from old columns to allow new data insertion - ALTER TABLE public.experiment_repetitions ALTER COLUMN experiment_number DROP NOT NULL; - ALTER TABLE public.experiment_repetitions ALTER COLUMN experiment_phase_id DROP NOT NULL; -END $$; - --- 2) Backfill experiment_id by joining on (experiment_number, experiment_phase_id) -> experiments(id) -UPDATE public.experiment_repetitions er -SET experiment_id = e.id -FROM public.experiments e -WHERE er.experiment_id IS NULL - AND e.experiment_number = er.experiment_number - AND e.phase_id = er.experiment_phase_id; - --- 3) Create trigger to auto-populate experiment_id for inserts -CREATE OR REPLACE FUNCTION public.set_experiment_id_on_repetition() -RETURNS TRIGGER AS $func$ -BEGIN - IF NEW.experiment_id IS NULL THEN - SELECT e.id INTO NEW.experiment_id - FROM public.experiments e - WHERE e.experiment_number = NEW.experiment_number - AND e.phase_id = NEW.experiment_phase_id; - - -- If still NULL, raise an error with helpful message - IF NEW.experiment_id IS NULL THEN - RAISE EXCEPTION 'Could not find experiment with experiment_number=% and phase_id=%', - NEW.experiment_number, NEW.experiment_phase_id; - END IF; - END IF; - RETURN NEW; -END; -$func$ LANGUAGE plpgsql; - -DROP TRIGGER IF EXISTS trg_set_experiment_id_on_repetition ON public.experiment_repetitions; -CREATE TRIGGER trg_set_experiment_id_on_repetition - BEFORE INSERT OR UPDATE OF experiment_number, experiment_phase_id ON public.experiment_repetitions - FOR EACH ROW - EXECUTE FUNCTION public.set_experiment_id_on_repetition(); - --- 4) Add FK and not null once backfilled and trigger is in place -ALTER TABLE public.experiment_repetitions - ADD CONSTRAINT experiment_repetitions_experiment_id_fkey - FOREIGN KEY (experiment_id) REFERENCES public.experiments(id) ON DELETE CASCADE; - -ALTER TABLE public.experiment_repetitions - ALTER COLUMN experiment_id SET NOT NULL; - --- 5) Create indexes to support queries used in app -CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_id ON public.experiment_repetitions(experiment_id); -CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_repetition_number ON public.experiment_repetitions(repetition_number); -CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_scheduled_date ON public.experiment_repetitions(scheduled_date); - --- 6) Maintain uniqueness: unique repetition_number per experiment_id -DO $$ -BEGIN - IF NOT EXISTS ( - SELECT 1 FROM pg_constraint - WHERE conname = 'uniq_experiment_repetition_number_per_experiment_id' - ) THEN - ALTER TABLE public.experiment_repetitions - ADD CONSTRAINT uniq_experiment_repetition_number_per_experiment_id - UNIQUE (experiment_id, repetition_number); - END IF; -END $$; - --- 6) Optional: keep legacy uniqueness on (experiment_number, experiment_phase_id, repetition_number) if desired --- This keeps backward compatibility with any existing references - --- 7) RLS already enabled; no change to policies necessary for added columns - - diff --git a/management-dashboard-web-app/supabase/migrations/20250927_fix_phase_tables_fk.sql b/management-dashboard-web-app/supabase/migrations/20250927_fix_phase_tables_fk.sql deleted file mode 100644 index e7b8df7..0000000 --- a/management-dashboard-web-app/supabase/migrations/20250927_fix_phase_tables_fk.sql +++ /dev/null @@ -1,235 +0,0 @@ --- Fix phase tables to use experiment_id instead of composite key --- This aligns the schema with application expectations - -BEGIN; - --- 1) Add experiment_id column to all phase tables and remove NOT NULL constraints from old columns -DO $$ -BEGIN - -- Soaking table - IF NOT EXISTS ( - SELECT 1 FROM information_schema.columns - WHERE table_schema = 'public' AND table_name = 'soaking' AND column_name = 'experiment_id' - ) THEN - ALTER TABLE public.soaking ADD COLUMN experiment_id UUID; - END IF; - - -- Remove NOT NULL constraints from old columns to allow new data insertion - ALTER TABLE public.soaking ALTER COLUMN experiment_number DROP NOT NULL; - ALTER TABLE public.soaking ALTER COLUMN experiment_phase_id DROP NOT NULL; - - -- Airdrying table - IF NOT EXISTS ( - SELECT 1 FROM information_schema.columns - WHERE table_schema = 'public' AND table_name = 'airdrying' AND column_name = 'experiment_id' - ) THEN - ALTER TABLE public.airdrying ADD COLUMN experiment_id UUID; - END IF; - - ALTER TABLE public.airdrying ALTER COLUMN experiment_number DROP NOT NULL; - ALTER TABLE public.airdrying ALTER COLUMN experiment_phase_id DROP NOT NULL; - - -- Cracking table - IF NOT EXISTS ( - SELECT 1 FROM information_schema.columns - WHERE table_schema = 'public' AND table_name = 'cracking' AND column_name = 'experiment_id' - ) THEN - ALTER TABLE public.cracking ADD COLUMN experiment_id UUID; - END IF; - - ALTER TABLE public.cracking ALTER COLUMN experiment_number DROP NOT NULL; - ALTER TABLE public.cracking ALTER COLUMN experiment_phase_id DROP NOT NULL; - - -- Shelling table - IF NOT EXISTS ( - SELECT 1 FROM information_schema.columns - WHERE table_schema = 'public' AND table_name = 'shelling' AND column_name = 'experiment_id' - ) THEN - ALTER TABLE public.shelling ADD COLUMN experiment_id UUID; - END IF; - - ALTER TABLE public.shelling ALTER COLUMN experiment_number DROP NOT NULL; - ALTER TABLE public.shelling ALTER COLUMN experiment_phase_id DROP NOT NULL; -END $$; - --- 2) Backfill experiment_id from composite key for all phase tables (only if old data exists) --- This migration is designed to work with existing data that has the old schema --- For fresh data, the seed files will populate experiment_id directly -DO $$ -BEGIN - -- Only backfill if there are records with the old schema (experiment_number is NOT NULL) - -- and experiment_id is NULL (meaning they haven't been migrated yet) - IF EXISTS (SELECT 1 FROM public.soaking WHERE experiment_id IS NULL AND experiment_number IS NOT NULL) THEN - UPDATE public.soaking s - SET experiment_id = e.id - FROM public.experiments e - WHERE s.experiment_id IS NULL - AND e.experiment_number = s.experiment_number - AND e.phase_id = s.experiment_phase_id; - END IF; - - IF EXISTS (SELECT 1 FROM public.airdrying WHERE experiment_id IS NULL AND experiment_number IS NOT NULL) THEN - UPDATE public.airdrying a - SET experiment_id = e.id - FROM public.experiments e - WHERE a.experiment_id IS NULL - AND e.experiment_number = a.experiment_number - AND e.phase_id = a.experiment_phase_id; - END IF; - - IF EXISTS (SELECT 1 FROM public.cracking WHERE experiment_id IS NULL AND experiment_number IS NOT NULL) THEN - UPDATE public.cracking c - SET experiment_id = e.id - FROM public.experiments e - WHERE c.experiment_id IS NULL - AND e.experiment_number = c.experiment_number - AND e.phase_id = c.experiment_phase_id; - END IF; - - IF EXISTS (SELECT 1 FROM public.shelling WHERE experiment_id IS NULL AND experiment_number IS NOT NULL) THEN - UPDATE public.shelling s - SET experiment_id = e.id - FROM public.experiments e - WHERE s.experiment_id IS NULL - AND e.experiment_number = s.experiment_number - AND e.phase_id = s.experiment_phase_id; - END IF; -END $$; - --- 3) Add foreign key constraints to experiments(id) -ALTER TABLE public.soaking - ADD CONSTRAINT soaking_experiment_id_fkey - FOREIGN KEY (experiment_id) REFERENCES public.experiments(id) ON DELETE CASCADE; - -ALTER TABLE public.airdrying - ADD CONSTRAINT airdrying_experiment_id_fkey - FOREIGN KEY (experiment_id) REFERENCES public.experiments(id) ON DELETE CASCADE; - -ALTER TABLE public.cracking - ADD CONSTRAINT cracking_experiment_id_fkey - FOREIGN KEY (experiment_id) REFERENCES public.experiments(id) ON DELETE CASCADE; - -ALTER TABLE public.shelling - ADD CONSTRAINT shelling_experiment_id_fkey - FOREIGN KEY (experiment_id) REFERENCES public.experiments(id) ON DELETE CASCADE; - --- 4) Create triggers to auto-populate experiment_id for phase tables -CREATE OR REPLACE FUNCTION public.set_experiment_id_on_soaking() -RETURNS TRIGGER AS $func$ -BEGIN - IF NEW.experiment_id IS NULL THEN - SELECT e.id INTO NEW.experiment_id - FROM public.experiments e - WHERE e.experiment_number = NEW.experiment_number - AND e.phase_id = NEW.experiment_phase_id; - END IF; - RETURN NEW; -END; -$func$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION public.set_experiment_id_on_airdrying() -RETURNS TRIGGER AS $func$ -BEGIN - IF NEW.experiment_id IS NULL THEN - SELECT e.id INTO NEW.experiment_id - FROM public.experiments e - WHERE e.experiment_number = NEW.experiment_number - AND e.phase_id = NEW.experiment_phase_id; - END IF; - RETURN NEW; -END; -$func$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION public.set_experiment_id_on_cracking() -RETURNS TRIGGER AS $func$ -BEGIN - IF NEW.experiment_id IS NULL THEN - SELECT e.id INTO NEW.experiment_id - FROM public.experiments e - WHERE e.experiment_number = NEW.experiment_number - AND e.phase_id = NEW.experiment_phase_id; - END IF; - RETURN NEW; -END; -$func$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION public.set_experiment_id_on_shelling() -RETURNS TRIGGER AS $func$ -BEGIN - IF NEW.experiment_id IS NULL THEN - SELECT e.id INTO NEW.experiment_id - FROM public.experiments e - WHERE e.experiment_number = NEW.experiment_number - AND e.phase_id = NEW.experiment_phase_id; - END IF; - RETURN NEW; -END; -$func$ LANGUAGE plpgsql; - --- Create triggers -DROP TRIGGER IF EXISTS trg_set_experiment_id_on_soaking ON public.soaking; -CREATE TRIGGER trg_set_experiment_id_on_soaking - BEFORE INSERT OR UPDATE OF experiment_number, experiment_phase_id ON public.soaking - FOR EACH ROW - EXECUTE FUNCTION public.set_experiment_id_on_soaking(); - -DROP TRIGGER IF EXISTS trg_set_experiment_id_on_airdrying ON public.airdrying; -CREATE TRIGGER trg_set_experiment_id_on_airdrying - BEFORE INSERT OR UPDATE OF experiment_number, experiment_phase_id ON public.airdrying - FOR EACH ROW - EXECUTE FUNCTION public.set_experiment_id_on_airdrying(); - -DROP TRIGGER IF EXISTS trg_set_experiment_id_on_cracking ON public.cracking; -CREATE TRIGGER trg_set_experiment_id_on_cracking - BEFORE INSERT OR UPDATE OF experiment_number, experiment_phase_id ON public.cracking - FOR EACH ROW - EXECUTE FUNCTION public.set_experiment_id_on_cracking(); - -DROP TRIGGER IF EXISTS trg_set_experiment_id_on_shelling ON public.shelling; -CREATE TRIGGER trg_set_experiment_id_on_shelling - BEFORE INSERT OR UPDATE OF experiment_number, experiment_phase_id ON public.shelling - FOR EACH ROW - EXECUTE FUNCTION public.set_experiment_id_on_shelling(); - --- 5) Make experiment_id NOT NULL after backfilling and triggers are in place --- Only do this if there are no NULL values -DO $$ -BEGIN - -- Check if all records have experiment_id populated before making it NOT NULL - IF NOT EXISTS (SELECT 1 FROM public.soaking WHERE experiment_id IS NULL) THEN - ALTER TABLE public.soaking ALTER COLUMN experiment_id SET NOT NULL; - END IF; - - IF NOT EXISTS (SELECT 1 FROM public.airdrying WHERE experiment_id IS NULL) THEN - ALTER TABLE public.airdrying ALTER COLUMN experiment_id SET NOT NULL; - END IF; - - IF NOT EXISTS (SELECT 1 FROM public.cracking WHERE experiment_id IS NULL) THEN - ALTER TABLE public.cracking ALTER COLUMN experiment_id SET NOT NULL; - END IF; - - IF NOT EXISTS (SELECT 1 FROM public.shelling WHERE experiment_id IS NULL) THEN - ALTER TABLE public.shelling ALTER COLUMN experiment_id SET NOT NULL; - END IF; -END $$; - --- 6) Create indexes for experiment_id -CREATE INDEX IF NOT EXISTS idx_soaking_experiment_id ON public.soaking(experiment_id); -CREATE INDEX IF NOT EXISTS idx_airdrying_experiment_id ON public.airdrying(experiment_id); -CREATE INDEX IF NOT EXISTS idx_cracking_experiment_id ON public.cracking(experiment_id); -CREATE INDEX IF NOT EXISTS idx_shelling_experiment_id ON public.shelling(experiment_id); - --- 7) Update unique constraints to use experiment_id instead of composite key --- Drop old unique constraints -ALTER TABLE public.soaking DROP CONSTRAINT IF EXISTS unique_soaking_per_experiment; -ALTER TABLE public.airdrying DROP CONSTRAINT IF EXISTS unique_airdrying_per_experiment; -ALTER TABLE public.cracking DROP CONSTRAINT IF EXISTS unique_cracking_per_experiment; -ALTER TABLE public.shelling DROP CONSTRAINT IF EXISTS unique_shelling_per_experiment; - --- Add new unique constraints using experiment_id -ALTER TABLE public.soaking ADD CONSTRAINT unique_soaking_per_experiment UNIQUE (experiment_id); -ALTER TABLE public.airdrying ADD CONSTRAINT unique_airdrying_per_experiment UNIQUE (experiment_id); -ALTER TABLE public.cracking ADD CONSTRAINT unique_cracking_per_experiment UNIQUE (experiment_id); -ALTER TABLE public.shelling ADD CONSTRAINT unique_shelling_per_experiment UNIQUE (experiment_id); - -COMMIT; diff --git a/management-dashboard-web-app/supabase/seed_04_phase2_jc_experiments_old.sql b/management-dashboard-web-app/supabase/seed_04_phase2_jc_experiments_old.sql index 554e81e..f3c2072 100644 --- a/management-dashboard-web-app/supabase/seed_04_phase2_jc_experiments_old.sql +++ b/management-dashboard-web-app/supabase/seed_04_phase2_jc_experiments_old.sql @@ -85,16 +85,14 @@ ON CONFLICT (experiment_number, phase_id) DO NOTHING; -- Create soaking records for Phase 2 JC experiments (1-20) INSERT INTO public.soaking ( - experiment_number, - experiment_phase_id, + experiment_id, scheduled_start_time, soaking_duration_hours, scheduled_end_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, NOW() + (e.experiment_number) * INTERVAL '1 day', CASE e.experiment_number WHEN 1 THEN 34 -- hours @@ -153,16 +151,14 @@ ON CONFLICT DO NOTHING; -- Create airdrying records for Phase 2 JC experiments (1-20) INSERT INTO public.airdrying ( - experiment_number, - experiment_phase_id, + experiment_id, scheduled_start_time, duration_minutes, scheduled_end_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days', -- Start 2 days after soaking CASE e.experiment_number WHEN 1 THEN 19 -- 19 minutes @@ -221,15 +217,13 @@ ON CONFLICT DO NOTHING; -- Create cracking records for Phase 2 JC experiments (1-20) INSERT INTO public.cracking ( - experiment_number, - experiment_phase_id, + experiment_id, machine_type_id, scheduled_start_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, (SELECT id FROM public.machine_types WHERE name = 'JC Cracker'), NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '3 days', -- Start 3 days after soaking e.created_by @@ -341,7 +335,7 @@ SELECT WHEN 20 THEN -0.09 END FROM public.experiments e -JOIN public.cracking c ON c.experiment_number = e.experiment_number AND c.experiment_phase_id = e.phase_id +JOIN public.cracking c ON c.experiment_id = e.id WHERE e.experiment_number BETWEEN 1 AND 20 AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments') ON CONFLICT DO NOTHING; @@ -353,15 +347,13 @@ ON CONFLICT DO NOTHING; -- Create experiment repetitions for Phase 2 JC experiments -- Each experiment needs 3 repetitions INSERT INTO public.experiment_repetitions ( - experiment_number, - experiment_phase_id, + experiment_id, repetition_number, status, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, rep_num, 'pending', e.created_by diff --git a/management-dashboard-web-app/supabase/seed_04_phase2_jc_experiments_updated.sql b/management-dashboard-web-app/supabase/seed_04_phase2_jc_experiments_updated.sql index 229cedd..46f6748 100644 --- a/management-dashboard-web-app/supabase/seed_04_phase2_jc_experiments_updated.sql +++ b/management-dashboard-web-app/supabase/seed_04_phase2_jc_experiments_updated.sql @@ -86,15 +86,13 @@ ON CONFLICT (experiment_number, phase_id) DO NOTHING; -- Create soaking records for Phase 2 JC experiments (1-20) INSERT INTO public.soaking ( experiment_id, - experiment_phase_id, scheduled_start_time, soaking_duration_minutes, scheduled_end_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, NOW() + (e.experiment_number) * INTERVAL '1 day', CASE e.experiment_number WHEN 1 THEN 34 * 60 -- 34 hours = 2040 minutes @@ -154,15 +152,13 @@ ON CONFLICT DO NOTHING; -- Create airdrying records for Phase 2 JC experiments (1-20) INSERT INTO public.airdrying ( experiment_id, - experiment_phase_id, scheduled_start_time, duration_minutes, scheduled_end_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days', -- Start 2 days after soaking CASE e.experiment_number WHEN 1 THEN 19 -- 19 minutes @@ -222,14 +218,12 @@ ON CONFLICT DO NOTHING; -- Create cracking records for Phase 2 JC experiments (1-20) INSERT INTO public.cracking ( experiment_id, - experiment_phase_id, machine_type_id, scheduled_start_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, (SELECT id FROM public.machine_types WHERE name = 'JC Cracker'), NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '3 days', -- Start 3 days after soaking e.created_by @@ -243,15 +237,14 @@ ON CONFLICT DO NOTHING; -- ============================================= -- Create JC cracker parameters for Phase 2 JC experiments (1-20) +-- First create the JC cracker parameters INSERT INTO public.jc_cracker_parameters ( - cracking_id, plate_contact_frequency_hz, throughput_rate_pecans_sec, crush_amount_in, entry_exit_height_diff_in ) -SELECT - c.id, +SELECT CASE e.experiment_number WHEN 1 THEN 53.0 WHEN 2 THEN 34.0 @@ -341,11 +334,31 @@ SELECT WHEN 20 THEN -0.09 END FROM public.experiments e -JOIN public.cracking c ON c.experiment_id = e.experiment_number AND c.experiment_phase_id = e.phase_id WHERE e.experiment_number BETWEEN 1 AND 20 AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments') ON CONFLICT DO NOTHING; +-- Now update the cracking records to reference the JC cracker parameters +-- Match them by the order they were created +WITH parameter_mapping AS ( + SELECT + e.experiment_number, + jcp.id as param_id, + ROW_NUMBER() OVER (ORDER BY e.experiment_number) as exp_rn, + ROW_NUMBER() OVER (ORDER BY jcp.created_at) as param_rn + FROM public.experiments e + CROSS JOIN public.jc_cracker_parameters jcp + WHERE e.experiment_number BETWEEN 1 AND 20 + AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Phase 2 of JC Experiments') +) +UPDATE public.cracking c +SET jc_cracker_parameters_id = pm.param_id +FROM parameter_mapping pm +JOIN public.experiments e ON c.experiment_id = e.id +WHERE e.experiment_number = pm.experiment_number +AND pm.exp_rn = pm.param_rn +AND c.jc_cracker_parameters_id IS NULL; + -- ============================================= -- CREATE EXPERIMENT REPETITIONS FOR PHASE 2 JC EXPERIMENTS -- ============================================= @@ -354,14 +367,12 @@ ON CONFLICT DO NOTHING; -- Each experiment needs 3 repetitions INSERT INTO public.experiment_repetitions ( experiment_id, - experiment_phase_id, repetition_number, status, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, rep_num, 'pending', e.created_by diff --git a/management-dashboard-web-app/supabase/seed_05_meyer_experiments_old.sql b/management-dashboard-web-app/supabase/seed_05_meyer_experiments_old.sql index c6c1f2f..54f34da 100644 --- a/management-dashboard-web-app/supabase/seed_05_meyer_experiments_old.sql +++ b/management-dashboard-web-app/supabase/seed_05_meyer_experiments_old.sql @@ -145,16 +145,14 @@ ON CONFLICT (experiment_number, phase_id) DO NOTHING; -- Create soaking records for Meyer experiments (1-40) INSERT INTO public.soaking ( - experiment_number, - experiment_phase_id, + experiment_id, scheduled_start_time, soaking_duration_hours, scheduled_end_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, NOW() + (e.experiment_number) * INTERVAL '1 day', CASE e.experiment_number WHEN 1 THEN 27 -- hours @@ -253,16 +251,14 @@ ON CONFLICT DO NOTHING; -- Create airdrying records for Meyer experiments (1-40) INSERT INTO public.airdrying ( - experiment_number, - experiment_phase_id, + experiment_id, scheduled_start_time, duration_minutes, scheduled_end_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days', -- Start 2 days after soaking CASE e.experiment_number WHEN 1 THEN 28 -- 28 minutes @@ -361,15 +357,13 @@ ON CONFLICT DO NOTHING; -- Create cracking records for Meyer experiments (1-40) INSERT INTO public.cracking ( - experiment_number, - experiment_phase_id, + experiment_id, machine_type_id, scheduled_start_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, (SELECT id FROM public.machine_types WHERE name = 'Meyer Cracker'), NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '3 days', -- Start 3 days after soaking e.created_by @@ -518,7 +512,7 @@ SELECT WHEN 40 THEN 2000.0 END FROM public.experiments e -JOIN public.cracking c ON c.experiment_number = e.experiment_number AND c.experiment_phase_id = e.phase_id +JOIN public.cracking c ON c.experiment_id = e.id WHERE e.experiment_number BETWEEN 1 AND 40 AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments') ON CONFLICT DO NOTHING; @@ -530,15 +524,13 @@ ON CONFLICT DO NOTHING; -- Create experiment repetitions for Meyer experiments -- Each experiment needs only 1 repetition INSERT INTO public.experiment_repetitions ( - experiment_number, - experiment_phase_id, + experiment_id, repetition_number, status, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, 1, 'pending', e.created_by diff --git a/management-dashboard-web-app/supabase/seed_05_meyer_experiments_updated.sql b/management-dashboard-web-app/supabase/seed_05_meyer_experiments_updated.sql index 8d7c780..d4dd2fb 100644 --- a/management-dashboard-web-app/supabase/seed_05_meyer_experiments_updated.sql +++ b/management-dashboard-web-app/supabase/seed_05_meyer_experiments_updated.sql @@ -146,15 +146,13 @@ ON CONFLICT (experiment_number, phase_id) DO NOTHING; -- Create soaking records for Meyer experiments (1-40) INSERT INTO public.soaking ( experiment_id, - experiment_phase_id, scheduled_start_time, soaking_duration_minutes, scheduled_end_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, NOW() + (e.experiment_number) * INTERVAL '1 day', CASE e.experiment_number WHEN 1 THEN 27 * 60 -- 27 hours = 1620 minutes @@ -254,15 +252,13 @@ ON CONFLICT DO NOTHING; -- Create airdrying records for Meyer experiments (1-40) INSERT INTO public.airdrying ( experiment_id, - experiment_phase_id, scheduled_start_time, duration_minutes, scheduled_end_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '2 days', -- Start 2 days after soaking CASE e.experiment_number WHEN 1 THEN 28 -- 28 minutes @@ -362,14 +358,12 @@ ON CONFLICT DO NOTHING; -- Create cracking records for Meyer experiments (1-40) INSERT INTO public.cracking ( experiment_id, - experiment_phase_id, machine_type_id, scheduled_start_time, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, (SELECT id FROM public.machine_types WHERE name = 'Meyer Cracker'), NOW() + (e.experiment_number) * INTERVAL '1 day' + INTERVAL '3 days', -- Start 3 days after soaking e.created_by @@ -383,14 +377,13 @@ ON CONFLICT DO NOTHING; -- ============================================= -- Create Meyer cracker parameters for Meyer experiments (1-40) +-- First create the Meyer cracker parameters INSERT INTO public.meyer_cracker_parameters ( - cracking_id, motor_speed_hz, jig_displacement_inches, spring_stiffness_nm ) -SELECT - c.id, +SELECT CASE e.experiment_number WHEN 1 THEN 33.0 WHEN 2 THEN 30.0 @@ -518,11 +511,31 @@ SELECT WHEN 40 THEN 2000.0 END FROM public.experiments e -JOIN public.cracking c ON c.experiment_id = e.experiment_number AND c.experiment_phase_id = e.phase_id WHERE e.experiment_number BETWEEN 1 AND 40 AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments') ON CONFLICT DO NOTHING; +-- Now update the cracking records to reference the Meyer cracker parameters +-- Match them by the order they were created +WITH parameter_mapping AS ( + SELECT + e.experiment_number, + mcp.id as param_id, + ROW_NUMBER() OVER (ORDER BY e.experiment_number) as exp_rn, + ROW_NUMBER() OVER (ORDER BY mcp.created_at) as param_rn + FROM public.experiments e + CROSS JOIN public.meyer_cracker_parameters mcp + WHERE e.experiment_number BETWEEN 1 AND 40 + AND e.phase_id = (SELECT id FROM public.experiment_phases WHERE name = 'Post Workshop Meyer Experiments') +) +UPDATE public.cracking c +SET meyer_cracker_parameters_id = pm.param_id +FROM parameter_mapping pm +JOIN public.experiments e ON c.experiment_id = e.id +WHERE e.experiment_number = pm.experiment_number +AND pm.exp_rn = pm.param_rn +AND c.meyer_cracker_parameters_id IS NULL; + -- ============================================= -- CREATE EXPERIMENT REPETITIONS FOR MEYER EXPERIMENTS -- ============================================= @@ -531,14 +544,12 @@ ON CONFLICT DO NOTHING; -- Each experiment needs only 1 repetition INSERT INTO public.experiment_repetitions ( experiment_id, - experiment_phase_id, repetition_number, status, created_by ) SELECT - e.experiment_number, - e.phase_id, + e.id, 1, 'pending', e.created_by