- Added additional notes to SESSION_SUMMARY.md regarding MQTT debugging and enhanced logging. - Removed outdated SQL seed files related to Phase 2 JC Experiments and Meyer Experiments to streamline the codebase. - Updated the CLI version in the Supabase configuration for consistency. - Cleaned up test files in the camera management API to improve maintainability.
289 lines
12 KiB
PL/PgSQL
289 lines
12 KiB
PL/PgSQL
-- Phase Data Tables
|
|
-- This migration creates phase-specific data entry tables (soaking, airdrying, cracking, shelling)
|
|
|
|
-- =============================================
|
|
-- 1. SOAKING TABLE
|
|
-- =============================================
|
|
|
|
CREATE TABLE IF NOT EXISTS public.soaking (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
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,
|
|
soaking_duration_minutes INTEGER NOT NULL CHECK (soaking_duration_minutes > 0),
|
|
scheduled_end_time TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
actual_end_time TIMESTAMP WITH TIME ZONE,
|
|
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 only one soaking per experiment or repetition
|
|
CONSTRAINT unique_soaking_per_experiment UNIQUE (experiment_id),
|
|
CONSTRAINT unique_soaking_per_repetition UNIQUE (repetition_id)
|
|
);
|
|
|
|
-- =============================================
|
|
-- 2. AIRDRYING TABLE
|
|
-- =============================================
|
|
|
|
CREATE TABLE IF NOT EXISTS public.airdrying (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
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,
|
|
duration_minutes INTEGER NOT NULL CHECK (duration_minutes > 0),
|
|
scheduled_end_time TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
actual_end_time TIMESTAMP WITH TIME ZONE,
|
|
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 only one airdrying per experiment or repetition
|
|
CONSTRAINT unique_airdrying_per_experiment UNIQUE (experiment_id),
|
|
CONSTRAINT unique_airdrying_per_repetition UNIQUE (repetition_id)
|
|
);
|
|
|
|
-- =============================================
|
|
-- 3. CRACKING TABLE
|
|
-- =============================================
|
|
|
|
CREATE TABLE IF NOT EXISTS public.cracking (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
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),
|
|
scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
actual_start_time TIMESTAMP WITH TIME ZONE,
|
|
actual_end_time TIMESTAMP WITH TIME ZONE,
|
|
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 only one cracking per experiment or repetition
|
|
CONSTRAINT unique_cracking_per_experiment UNIQUE (experiment_id),
|
|
CONSTRAINT unique_cracking_per_repetition UNIQUE (repetition_id)
|
|
);
|
|
|
|
-- =============================================
|
|
-- 4. SHELLING TABLE
|
|
-- =============================================
|
|
|
|
CREATE TABLE IF NOT EXISTS public.shelling (
|
|
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
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,
|
|
actual_end_time TIMESTAMP WITH TIME ZONE,
|
|
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 only one shelling per experiment or repetition
|
|
CONSTRAINT unique_shelling_per_experiment UNIQUE (experiment_id),
|
|
CONSTRAINT unique_shelling_per_repetition UNIQUE (repetition_id)
|
|
);
|
|
|
|
-- =============================================
|
|
-- 5. INDEXES FOR PERFORMANCE
|
|
-- =============================================
|
|
|
|
-- 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);
|
|
CREATE INDEX IF NOT EXISTS idx_airdrying_repetition_id ON public.airdrying(repetition_id);
|
|
CREATE INDEX IF NOT EXISTS idx_cracking_repetition_id ON public.cracking(repetition_id);
|
|
CREATE INDEX IF NOT EXISTS idx_shelling_repetition_id ON public.shelling(repetition_id);
|
|
|
|
-- Create indexes for machine type references
|
|
CREATE INDEX IF NOT EXISTS idx_cracking_machine_type_id ON public.cracking(machine_type_id);
|
|
|
|
-- Create indexes for created_by references
|
|
CREATE INDEX IF NOT EXISTS idx_soaking_created_by ON public.soaking(created_by);
|
|
CREATE INDEX IF NOT EXISTS idx_airdrying_created_by ON public.airdrying(created_by);
|
|
CREATE INDEX IF NOT EXISTS idx_cracking_created_by ON public.cracking(created_by);
|
|
CREATE INDEX IF NOT EXISTS idx_shelling_created_by ON public.shelling(created_by);
|
|
|
|
-- =============================================
|
|
-- 6. TRIGGER FUNCTIONS FOR AUTOMATIC TIMESTAMP CALCULATIONS
|
|
-- =============================================
|
|
|
|
-- Function to calculate scheduled end time for soaking
|
|
CREATE OR REPLACE FUNCTION calculate_soaking_scheduled_end_time()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.scheduled_end_time = NEW.scheduled_start_time + (NEW.soaking_duration_minutes || ' minutes')::INTERVAL;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Function to calculate scheduled end time for airdrying
|
|
CREATE OR REPLACE FUNCTION calculate_airdrying_scheduled_end_time()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.scheduled_end_time = NEW.scheduled_start_time + (NEW.duration_minutes || ' minutes')::INTERVAL;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Function to set airdrying scheduled start time based on soaking end time
|
|
CREATE OR REPLACE FUNCTION set_airdrying_scheduled_start_time()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
-- If this is a new airdrying record and no scheduled_start_time is provided,
|
|
-- try to get it from the associated soaking's scheduled_end_time
|
|
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_id = NEW.experiment_id
|
|
LIMIT 1;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Function to set cracking scheduled start time based on airdrying end time
|
|
CREATE OR REPLACE FUNCTION set_cracking_scheduled_start_time()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
-- If this is a new cracking record and no scheduled_start_time is provided,
|
|
-- try to get it from the associated airdrying's scheduled_end_time
|
|
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_id = NEW.experiment_id
|
|
LIMIT 1;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- =============================================
|
|
-- 7. TRIGGERS
|
|
-- =============================================
|
|
|
|
-- Triggers for automatic timestamp calculations
|
|
DROP TRIGGER IF EXISTS trigger_calculate_soaking_scheduled_end_time ON public.soaking;
|
|
CREATE TRIGGER trigger_calculate_soaking_scheduled_end_time
|
|
BEFORE INSERT OR UPDATE ON public.soaking
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION calculate_soaking_scheduled_end_time();
|
|
|
|
DROP TRIGGER IF EXISTS trigger_calculate_airdrying_scheduled_end_time ON public.airdrying;
|
|
CREATE TRIGGER trigger_calculate_airdrying_scheduled_end_time
|
|
BEFORE INSERT OR UPDATE ON public.airdrying
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION calculate_airdrying_scheduled_end_time();
|
|
|
|
DROP TRIGGER IF EXISTS trigger_set_airdrying_scheduled_start_time ON public.airdrying;
|
|
CREATE TRIGGER trigger_set_airdrying_scheduled_start_time
|
|
BEFORE INSERT ON public.airdrying
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION set_airdrying_scheduled_start_time();
|
|
|
|
DROP TRIGGER IF EXISTS trigger_set_cracking_scheduled_start_time ON public.cracking;
|
|
CREATE TRIGGER trigger_set_cracking_scheduled_start_time
|
|
BEFORE INSERT ON public.cracking
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION set_cracking_scheduled_start_time();
|
|
|
|
-- Triggers for updated_at on all phase tables
|
|
CREATE TRIGGER set_updated_at_soaking
|
|
BEFORE UPDATE ON public.soaking
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.handle_updated_at();
|
|
|
|
CREATE TRIGGER set_updated_at_airdrying
|
|
BEFORE UPDATE ON public.airdrying
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.handle_updated_at();
|
|
|
|
CREATE TRIGGER set_updated_at_cracking
|
|
BEFORE UPDATE ON public.cracking
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.handle_updated_at();
|
|
|
|
CREATE TRIGGER set_updated_at_shelling
|
|
BEFORE UPDATE ON public.shelling
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.handle_updated_at();
|
|
|
|
-- =============================================
|
|
-- 8. GRANT PERMISSIONS
|
|
-- =============================================
|
|
|
|
GRANT ALL ON public.soaking TO authenticated;
|
|
GRANT ALL ON public.airdrying TO authenticated;
|
|
GRANT ALL ON public.cracking TO authenticated;
|
|
GRANT ALL ON public.shelling TO authenticated;
|
|
|
|
-- =============================================
|
|
-- 9. ENABLE ROW LEVEL SECURITY
|
|
-- =============================================
|
|
|
|
ALTER TABLE public.soaking ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.airdrying ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.cracking ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.shelling ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- =============================================
|
|
-- 10. CREATE RLS POLICIES
|
|
-- =============================================
|
|
|
|
-- Create RLS policies for phase tables
|
|
CREATE POLICY "Soaking data is viewable by authenticated users" ON public.soaking
|
|
FOR SELECT USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Soaking data is insertable by authenticated users" ON public.soaking
|
|
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Soaking data is updatable by authenticated users" ON public.soaking
|
|
FOR UPDATE USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Soaking data is deletable by authenticated users" ON public.soaking
|
|
FOR DELETE USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Airdrying data is viewable by authenticated users" ON public.airdrying
|
|
FOR SELECT USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Airdrying data is insertable by authenticated users" ON public.airdrying
|
|
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Airdrying data is updatable by authenticated users" ON public.airdrying
|
|
FOR UPDATE USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Airdrying data is deletable by authenticated users" ON public.airdrying
|
|
FOR DELETE USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Cracking data is viewable by authenticated users" ON public.cracking
|
|
FOR SELECT USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Cracking data is insertable by authenticated users" ON public.cracking
|
|
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Cracking data is updatable by authenticated users" ON public.cracking
|
|
FOR UPDATE USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Cracking data is deletable by authenticated users" ON public.cracking
|
|
FOR DELETE USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Shelling data is viewable by authenticated users" ON public.shelling
|
|
FOR SELECT USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Shelling data is insertable by authenticated users" ON public.shelling
|
|
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Shelling data is updatable by authenticated users" ON public.shelling
|
|
FOR UPDATE USING (auth.role() = 'authenticated');
|
|
|
|
CREATE POLICY "Shelling data is deletable by authenticated users" ON public.shelling
|
|
FOR DELETE USING (auth.role() = 'authenticated');
|
|
|