-- Complete Database Schema for USDA Vision Pecan Experiments System -- This migration creates the entire database schema from scratch -- Enable necessary extensions CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- ============================================= -- 1. ROLES AND USER MANAGEMENT -- ============================================= -- Create roles table CREATE TABLE IF NOT EXISTS public.roles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name TEXT UNIQUE NOT NULL CHECK (name IN ('admin', 'conductor', 'analyst', 'data recorder')), description TEXT NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Create user_profiles table to extend auth.users CREATE TABLE IF NOT EXISTS public.user_profiles ( id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE, email TEXT NOT NULL, status TEXT DEFAULT 'active' CHECK (status IN ('active', 'disabled')), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Create user_roles junction table for many-to-many relationship CREATE TABLE IF NOT EXISTS public.user_roles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES public.user_profiles(id) ON DELETE CASCADE, role_id UUID NOT NULL REFERENCES public.roles(id) ON DELETE CASCADE, assigned_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), assigned_by UUID REFERENCES public.user_profiles(id), UNIQUE(user_id, role_id) ); -- ============================================= -- 2. EXPERIMENT PHASES -- ============================================= -- Create experiment_phases table CREATE TABLE IF NOT EXISTS public.experiment_phases ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name TEXT NOT NULL UNIQUE, description TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by UUID NOT NULL REFERENCES public.user_profiles(id) ); -- ============================================= -- 3. EXPERIMENTS -- ============================================= -- Create experiments table CREATE TABLE IF NOT EXISTS public.experiments ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), experiment_number INTEGER UNIQUE NOT NULL, reps_required INTEGER NOT NULL CHECK (reps_required > 0), soaking_duration_hr FLOAT NOT NULL CHECK (soaking_duration_hr >= 0), air_drying_time_min INTEGER NOT NULL CHECK (air_drying_time_min >= 0), plate_contact_frequency_hz FLOAT NOT NULL CHECK (plate_contact_frequency_hz > 0), throughput_rate_pecans_sec FLOAT NOT NULL CHECK (throughput_rate_pecans_sec > 0), crush_amount_in FLOAT NOT NULL CHECK (crush_amount_in >= 0), entry_exit_height_diff_in FLOAT NOT NULL, results_status TEXT NOT NULL DEFAULT 'valid' CHECK (results_status IN ('valid', 'invalid')), completion_status BOOLEAN NOT NULL DEFAULT false, phase_id UUID REFERENCES public.experiment_phases(id) ON DELETE SET NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by UUID NOT NULL REFERENCES public.user_profiles(id) ); -- ============================================= -- 4. EXPERIMENT REPETITIONS -- ============================================= -- Create experiment_repetitions table CREATE TABLE IF NOT EXISTS public.experiment_repetitions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_number INTEGER NOT NULL CHECK (repetition_number > 0), scheduled_date TIMESTAMP WITH TIME ZONE, schedule_status TEXT NOT NULL DEFAULT 'pending schedule' CHECK (schedule_status IN ('pending schedule', 'scheduled', 'canceled', 'aborted')), completion_status BOOLEAN NOT NULL DEFAULT false, is_locked BOOLEAN NOT NULL DEFAULT false, locked_at TIMESTAMP WITH TIME ZONE, locked_by UUID REFERENCES public.user_profiles(id), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by UUID NOT NULL REFERENCES public.user_profiles(id), -- Ensure unique repetition numbers per experiment CONSTRAINT unique_repetition_per_experiment UNIQUE (experiment_id, repetition_number) ); -- ============================================= -- 5. DATA ENTRY SYSTEM -- ============================================= -- Create experiment_phase_drafts table for phase-specific draft management CREATE TABLE IF NOT EXISTS public.experiment_phase_drafts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE, repetition_id UUID NOT NULL REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES public.user_profiles(id), phase_name TEXT NOT NULL CHECK (phase_name IN ('pre-soaking', 'air-drying', 'cracking', 'shelling')), status TEXT NOT NULL DEFAULT 'draft' CHECK (status IN ('draft', 'submitted', 'withdrawn')), draft_name TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), submitted_at TIMESTAMP WITH TIME ZONE, withdrawn_at TIMESTAMP WITH TIME ZONE ); -- Create experiment_phase_data table for phase-specific measurements CREATE TABLE IF NOT EXISTS public.experiment_phase_data ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), phase_draft_id UUID NOT NULL REFERENCES public.experiment_phase_drafts(id) ON DELETE CASCADE, phase_name TEXT NOT NULL CHECK (phase_name IN ('pre-soaking', 'air-drying', 'cracking', 'shelling')), -- Pre-soaking phase data batch_initial_weight_lbs FLOAT CHECK (batch_initial_weight_lbs >= 0), initial_shell_moisture_pct FLOAT CHECK (initial_shell_moisture_pct >= 0 AND initial_shell_moisture_pct <= 100), initial_kernel_moisture_pct FLOAT CHECK (initial_kernel_moisture_pct >= 0 AND initial_kernel_moisture_pct <= 100), soaking_start_time TIMESTAMP WITH TIME ZONE, -- Air-drying phase data airdrying_start_time TIMESTAMP WITH TIME ZONE, post_soak_weight_lbs FLOAT CHECK (post_soak_weight_lbs >= 0), post_soak_kernel_moisture_pct FLOAT CHECK (post_soak_kernel_moisture_pct >= 0 AND post_soak_kernel_moisture_pct <= 100), post_soak_shell_moisture_pct FLOAT CHECK (post_soak_shell_moisture_pct >= 0 AND post_soak_shell_moisture_pct <= 100), avg_pecan_diameter_in FLOAT CHECK (avg_pecan_diameter_in >= 0), -- Cracking phase data cracking_start_time TIMESTAMP WITH TIME ZONE, -- Shelling phase data shelling_start_time TIMESTAMP WITH TIME ZONE, bin_1_weight_lbs FLOAT CHECK (bin_1_weight_lbs >= 0), bin_2_weight_lbs FLOAT CHECK (bin_2_weight_lbs >= 0), bin_3_weight_lbs FLOAT CHECK (bin_3_weight_lbs >= 0), discharge_bin_weight_lbs FLOAT CHECK (discharge_bin_weight_lbs >= 0), bin_1_full_yield_oz FLOAT CHECK (bin_1_full_yield_oz >= 0), bin_2_full_yield_oz FLOAT CHECK (bin_2_full_yield_oz >= 0), bin_3_full_yield_oz FLOAT CHECK (bin_3_full_yield_oz >= 0), bin_1_half_yield_oz FLOAT CHECK (bin_1_half_yield_oz >= 0), bin_2_half_yield_oz FLOAT CHECK (bin_2_half_yield_oz >= 0), bin_3_half_yield_oz FLOAT CHECK (bin_3_half_yield_oz >= 0), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Constraint: One record per phase draft CONSTRAINT unique_phase_per_draft UNIQUE (phase_draft_id, phase_name) ); -- Create pecan_diameter_measurements table for individual diameter measurements CREATE TABLE IF NOT EXISTS public.pecan_diameter_measurements ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), phase_data_id UUID NOT NULL REFERENCES public.experiment_phase_data(id) ON DELETE CASCADE, measurement_number INTEGER NOT NULL CHECK (measurement_number >= 1 AND measurement_number <= 10), diameter_in FLOAT NOT NULL CHECK (diameter_in >= 0), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Constraint: Unique measurement number per phase data CONSTRAINT unique_measurement_per_phase UNIQUE (phase_data_id, measurement_number) ); -- ============================================= -- 6. INDEXES FOR PERFORMANCE -- ============================================= -- User management indexes CREATE INDEX IF NOT EXISTS idx_user_profiles_email ON public.user_profiles(email); CREATE INDEX IF NOT EXISTS idx_user_profiles_status ON public.user_profiles(status); CREATE INDEX IF NOT EXISTS idx_user_roles_user_id ON public.user_roles(user_id); CREATE INDEX IF NOT EXISTS idx_user_roles_role_id ON public.user_roles(role_id); -- Experiment phases indexes CREATE INDEX IF NOT EXISTS idx_experiment_phases_name ON public.experiment_phases(name); CREATE INDEX IF NOT EXISTS idx_experiment_phases_created_by ON public.experiment_phases(created_by); -- Experiments indexes CREATE INDEX IF NOT EXISTS idx_experiments_experiment_number ON public.experiments(experiment_number); CREATE INDEX IF NOT EXISTS idx_experiments_created_by ON public.experiments(created_by); CREATE INDEX IF NOT EXISTS idx_experiments_results_status ON public.experiments(results_status); CREATE INDEX IF NOT EXISTS idx_experiments_completion_status ON public.experiments(completion_status); CREATE INDEX IF NOT EXISTS idx_experiments_created_at ON public.experiments(created_at); CREATE INDEX IF NOT EXISTS idx_experiments_phase_id ON public.experiments(phase_id); -- Experiment repetitions indexes CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_experiment_id ON public.experiment_repetitions(experiment_id); CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_schedule_status ON public.experiment_repetitions(schedule_status); CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_completion_status ON public.experiment_repetitions(completion_status); CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_scheduled_date ON public.experiment_repetitions(scheduled_date); CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_created_by ON public.experiment_repetitions(created_by); CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_created_at ON public.experiment_repetitions(created_at); CREATE INDEX IF NOT EXISTS idx_experiment_repetitions_is_locked ON public.experiment_repetitions(is_locked); -- Data entry system indexes CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_experiment_id ON public.experiment_phase_drafts(experiment_id); CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_repetition_id ON public.experiment_phase_drafts(repetition_id); CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_user_id ON public.experiment_phase_drafts(user_id); CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_phase_name ON public.experiment_phase_drafts(phase_name); CREATE INDEX IF NOT EXISTS idx_experiment_phase_drafts_status ON public.experiment_phase_drafts(status); CREATE INDEX IF NOT EXISTS idx_experiment_phase_data_draft_id ON public.experiment_phase_data(phase_draft_id); CREATE INDEX IF NOT EXISTS idx_experiment_phase_data_phase_name ON public.experiment_phase_data(phase_name); CREATE INDEX IF NOT EXISTS idx_pecan_diameter_measurements_phase_data_id ON public.pecan_diameter_measurements(phase_data_id); -- ============================================= -- 7. TRIGGERS AND FUNCTIONS -- ============================================= -- Create updated_at trigger function CREATE OR REPLACE FUNCTION public.handle_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Create triggers for updated_at CREATE TRIGGER set_updated_at_roles BEFORE UPDATE ON public.roles FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_user_profiles BEFORE UPDATE ON public.user_profiles FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_experiment_phases BEFORE UPDATE ON public.experiment_phases FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_experiments BEFORE UPDATE ON public.experiments FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_experiment_repetitions BEFORE UPDATE ON public.experiment_repetitions FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_experiment_phase_drafts BEFORE UPDATE ON public.experiment_phase_drafts FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); CREATE TRIGGER set_updated_at_experiment_phase_data BEFORE UPDATE ON public.experiment_phase_data FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); -- Function to validate repetition number doesn't exceed experiment's reps_required CREATE OR REPLACE FUNCTION validate_repetition_number() RETURNS TRIGGER AS $$ DECLARE max_reps INTEGER; BEGIN -- Get the reps_required for this experiment SELECT reps_required INTO max_reps FROM public.experiments WHERE id = NEW.experiment_id; -- Check if repetition number exceeds the limit IF NEW.repetition_number > max_reps THEN RAISE EXCEPTION 'Repetition number % exceeds maximum allowed repetitions % for experiment', NEW.repetition_number, max_reps; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Create trigger to validate repetition number CREATE TRIGGER trigger_validate_repetition_number BEFORE INSERT OR UPDATE ON public.experiment_repetitions FOR EACH ROW EXECUTE FUNCTION validate_repetition_number(); -- Function to handle phase draft status changes CREATE OR REPLACE FUNCTION public.handle_phase_draft_status_change() RETURNS TRIGGER AS $$ BEGIN -- Set submitted_at when status changes to 'submitted' IF NEW.status = 'submitted' AND OLD.status != 'submitted' THEN NEW.submitted_at = NOW(); NEW.withdrawn_at = NULL; END IF; -- Set withdrawn_at when status changes to 'withdrawn' IF NEW.status = 'withdrawn' AND OLD.status = 'submitted' THEN NEW.withdrawn_at = NOW(); END IF; -- Clear timestamps when status changes back to 'draft' IF NEW.status = 'draft' AND OLD.status IN ('submitted', 'withdrawn') THEN NEW.submitted_at = NULL; NEW.withdrawn_at = NULL; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER set_timestamps_experiment_phase_drafts BEFORE UPDATE ON public.experiment_phase_drafts FOR EACH ROW EXECUTE FUNCTION public.handle_phase_draft_status_change(); -- ============================================= -- 8. HELPER FUNCTIONS -- ============================================= -- Helper function to get current user's roles CREATE OR REPLACE FUNCTION public.get_user_roles() RETURNS TEXT[] AS $$ BEGIN RETURN ARRAY( SELECT r.name FROM public.user_roles ur JOIN public.roles r ON ur.role_id = r.id WHERE ur.user_id = auth.uid() ); END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Helper function to get current user's first role (for backward compatibility) CREATE OR REPLACE FUNCTION public.get_user_role() RETURNS TEXT AS $$ BEGIN -- Return the first role found (for backward compatibility) RETURN ( SELECT r.name FROM public.user_roles ur JOIN public.roles r ON ur.role_id = r.id WHERE ur.user_id = auth.uid() LIMIT 1 ); END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Helper function to check if user is admin CREATE OR REPLACE FUNCTION public.is_admin() RETURNS BOOLEAN AS $$ BEGIN RETURN 'admin' = ANY(public.get_user_roles()); END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Helper function to check if user has specific role CREATE OR REPLACE FUNCTION public.has_role(role_name TEXT) RETURNS BOOLEAN AS $$ BEGIN RETURN role_name = ANY(public.get_user_roles()); END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Helper function to check if user can manage experiments CREATE OR REPLACE FUNCTION public.can_manage_experiments() RETURNS BOOLEAN AS $$ BEGIN RETURN EXISTS ( SELECT 1 FROM public.user_roles ur JOIN public.roles r ON ur.role_id = r.id WHERE ur.user_id = auth.uid() AND r.name IN ('admin', 'conductor') ); END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Function to generate secure temporary password CREATE OR REPLACE FUNCTION public.generate_temp_password() RETURNS TEXT AS $$ DECLARE chars TEXT := 'ABCDEFGHJKMNPQRSTUVWXYZabcdefghijkmnpqrstuvwxyz23456789'; result TEXT := ''; i INTEGER; BEGIN FOR i IN 1..12 LOOP result := result || substr(chars, floor(random() * length(chars) + 1)::integer, 1); END LOOP; RETURN result; END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Function to create user with roles (for admin use) CREATE OR REPLACE FUNCTION public.create_user_with_roles( user_email TEXT, role_names TEXT[], temp_password TEXT DEFAULT NULL ) RETURNS JSON AS $$ DECLARE new_user_id UUID; role_record RECORD; generated_password TEXT; result JSON; role_count INTEGER; BEGIN -- Only admins can create users IF NOT public.is_admin() THEN RAISE EXCEPTION 'Only administrators can create users'; END IF; -- Validate that at least one role is provided IF array_length(role_names, 1) IS NULL OR array_length(role_names, 1) = 0 THEN RAISE EXCEPTION 'At least one role must be assigned to the user'; END IF; -- Validate that all provided roles exist SELECT COUNT(*) INTO role_count FROM public.roles WHERE name = ANY(role_names); IF role_count != array_length(role_names, 1) THEN RAISE EXCEPTION 'One or more specified roles do not exist'; END IF; -- Check if user already exists IF EXISTS (SELECT 1 FROM auth.users WHERE email = user_email) THEN RAISE EXCEPTION 'User with email % already exists', user_email; END IF; -- Generate password if not provided IF temp_password IS NULL THEN generated_password := public.generate_temp_password(); ELSE generated_password := temp_password; END IF; -- Generate new user ID new_user_id := uuid_generate_v4(); -- Insert into auth.users (simulating user creation) INSERT INTO auth.users ( instance_id, id, aud, role, email, encrypted_password, email_confirmed_at, created_at, updated_at, confirmation_token, email_change, email_change_token_new, recovery_token ) VALUES ( '00000000-0000-0000-0000-000000000000', new_user_id, 'authenticated', 'authenticated', user_email, crypt(generated_password, gen_salt('bf')), NOW(), NOW(), NOW(), '', '', '', '' ); -- Insert user profile INSERT INTO public.user_profiles (id, email, status) VALUES (new_user_id, user_email, 'active'); -- Assign roles through the user_roles junction table FOR role_record IN SELECT id FROM public.roles WHERE name = ANY(role_names) LOOP INSERT INTO public.user_roles (user_id, role_id, assigned_by) VALUES (new_user_id, role_record.id, auth.uid()); END LOOP; -- Return result result := json_build_object( 'user_id', new_user_id, 'email', user_email, 'temp_password', generated_password, 'roles', role_names, 'status', 'active' ); RETURN result; EXCEPTION WHEN OTHERS THEN -- Clean up any partial inserts DELETE FROM public.user_roles WHERE user_id = new_user_id; DELETE FROM public.user_profiles WHERE id = new_user_id; DELETE FROM auth.users WHERE id = new_user_id; RAISE; END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- ============================================= -- 9. ROW LEVEL SECURITY (RLS) -- ============================================= -- Enable RLS on all tables ALTER TABLE public.roles ENABLE ROW LEVEL SECURITY; ALTER TABLE public.user_profiles ENABLE ROW LEVEL SECURITY; ALTER TABLE public.user_roles ENABLE ROW LEVEL SECURITY; ALTER TABLE public.experiment_phases ENABLE ROW LEVEL SECURITY; ALTER TABLE public.experiments ENABLE ROW LEVEL SECURITY; ALTER TABLE public.experiment_repetitions ENABLE ROW LEVEL SECURITY; ALTER TABLE public.experiment_phase_drafts ENABLE ROW LEVEL SECURITY; ALTER TABLE public.experiment_phase_data ENABLE ROW LEVEL SECURITY; ALTER TABLE public.pecan_diameter_measurements ENABLE ROW LEVEL SECURITY; -- Roles table policies CREATE POLICY "Anyone can read roles" ON public.roles FOR SELECT USING (true); CREATE POLICY "Only admins can insert roles" ON public.roles FOR INSERT WITH CHECK (public.is_admin()); CREATE POLICY "Only admins can update roles" ON public.roles FOR UPDATE USING (public.is_admin()); CREATE POLICY "Only admins can delete roles" ON public.roles FOR DELETE USING (public.is_admin()); -- User profiles policies CREATE POLICY "Users can read own profile, admins can read all" ON public.user_profiles FOR SELECT USING ( auth.uid() = id OR public.is_admin() ); CREATE POLICY "Only admins can insert user profiles" ON public.user_profiles FOR INSERT WITH CHECK (public.is_admin()); CREATE POLICY "Users can update own profile, admins can update any" ON public.user_profiles FOR UPDATE USING ( auth.uid() = id OR public.is_admin() ); CREATE POLICY "Only admins can delete user profiles" ON public.user_profiles FOR DELETE USING (public.is_admin()); -- User roles policies CREATE POLICY "Users can read own roles, admins can read all" ON public.user_roles FOR SELECT USING ( user_id = auth.uid() OR public.is_admin() ); CREATE POLICY "Only admins can assign roles" ON public.user_roles FOR INSERT WITH CHECK (public.is_admin()); CREATE POLICY "Only admins can update role assignments" ON public.user_roles FOR UPDATE USING (public.is_admin()); CREATE POLICY "Only admins can remove role assignments" ON public.user_roles FOR DELETE USING (public.is_admin()); -- Experiment phases policies CREATE POLICY "experiment_phases_select_policy" ON public.experiment_phases FOR SELECT TO authenticated USING (true); CREATE POLICY "experiment_phases_insert_policy" ON public.experiment_phases FOR INSERT TO authenticated WITH CHECK (public.can_manage_experiments()); CREATE POLICY "experiment_phases_update_policy" ON public.experiment_phases FOR UPDATE TO authenticated USING (public.can_manage_experiments()) WITH CHECK (public.can_manage_experiments()); CREATE POLICY "experiment_phases_delete_policy" ON public.experiment_phases FOR DELETE TO authenticated USING (public.is_admin()); -- Experiments policies CREATE POLICY "experiments_select_policy" ON public.experiments FOR SELECT TO authenticated USING (true); CREATE POLICY "experiments_insert_policy" ON public.experiments FOR INSERT TO authenticated WITH CHECK (public.can_manage_experiments()); CREATE POLICY "experiments_update_policy" ON public.experiments FOR UPDATE TO authenticated USING (public.can_manage_experiments()) WITH CHECK (public.can_manage_experiments()); CREATE POLICY "experiments_delete_policy" ON public.experiments FOR DELETE TO authenticated USING (public.is_admin()); -- Experiment repetitions policies CREATE POLICY "Users can view experiment repetitions" ON public.experiment_repetitions FOR SELECT TO authenticated USING (true); CREATE POLICY "Users can create experiment repetitions" ON public.experiment_repetitions FOR INSERT WITH CHECK ( experiment_id IN ( SELECT id FROM public.experiments WHERE created_by = auth.uid() ) OR public.is_admin() ); CREATE POLICY "Users can update experiment repetitions" ON public.experiment_repetitions FOR UPDATE USING ( experiment_id IN ( SELECT id FROM public.experiments WHERE created_by = auth.uid() ) OR public.is_admin() ); CREATE POLICY "Users can delete experiment repetitions" ON public.experiment_repetitions FOR DELETE USING ( experiment_id IN ( SELECT id FROM public.experiments WHERE created_by = auth.uid() ) OR public.is_admin() ); -- Experiment phase drafts policies CREATE POLICY "experiment_phase_drafts_select_policy" ON public.experiment_phase_drafts FOR SELECT TO authenticated USING (true); CREATE POLICY "experiment_phase_drafts_insert_policy" ON public.experiment_phase_drafts FOR INSERT TO authenticated WITH CHECK (user_id = auth.uid()); CREATE POLICY "experiment_phase_drafts_update_policy" ON public.experiment_phase_drafts FOR UPDATE TO authenticated USING ( (user_id = auth.uid() AND NOT EXISTS ( SELECT 1 FROM public.experiment_repetitions WHERE id = repetition_id AND is_locked = true )) OR public.is_admin() ) WITH CHECK ( (user_id = auth.uid() AND NOT EXISTS ( SELECT 1 FROM public.experiment_repetitions WHERE id = repetition_id AND is_locked = true )) OR public.is_admin() ); CREATE POLICY "experiment_phase_drafts_delete_policy" ON public.experiment_phase_drafts FOR DELETE TO authenticated USING ( (user_id = auth.uid() AND status = 'draft' AND NOT EXISTS ( SELECT 1 FROM public.experiment_repetitions WHERE id = repetition_id AND is_locked = true )) OR public.is_admin() ); -- Experiment phase data policies CREATE POLICY "experiment_phase_data_select_policy" ON public.experiment_phase_data FOR SELECT TO authenticated USING (true); CREATE POLICY "experiment_phase_data_insert_policy" ON public.experiment_phase_data FOR INSERT TO authenticated WITH CHECK ( EXISTS ( SELECT 1 FROM public.experiment_phase_drafts epd WHERE epd.id = phase_draft_id AND epd.user_id = auth.uid() ) ); CREATE POLICY "experiment_phase_data_update_policy" ON public.experiment_phase_data FOR UPDATE TO authenticated USING ( EXISTS ( SELECT 1 FROM public.experiment_phase_drafts epd WHERE epd.id = phase_draft_id AND epd.user_id = auth.uid() ) ) WITH CHECK ( EXISTS ( SELECT 1 FROM public.experiment_phase_drafts epd WHERE epd.id = phase_draft_id AND epd.user_id = auth.uid() ) ); CREATE POLICY "experiment_phase_data_delete_policy" ON public.experiment_phase_data FOR DELETE TO authenticated USING ( EXISTS ( SELECT 1 FROM public.experiment_phase_drafts epd WHERE epd.id = phase_draft_id AND epd.user_id = auth.uid() AND epd.status = 'draft' ) ); -- Pecan diameter measurements policies CREATE POLICY "pecan_diameter_measurements_select_policy" ON public.pecan_diameter_measurements FOR SELECT TO authenticated USING (true); CREATE POLICY "pecan_diameter_measurements_insert_policy" ON public.pecan_diameter_measurements FOR INSERT TO authenticated WITH CHECK ( EXISTS ( SELECT 1 FROM public.experiment_phase_data epd JOIN public.experiment_phase_drafts epdr ON epd.phase_draft_id = epdr.id WHERE epd.id = phase_data_id AND epdr.user_id = auth.uid() ) ); CREATE POLICY "pecan_diameter_measurements_update_policy" ON public.pecan_diameter_measurements FOR UPDATE TO authenticated USING ( EXISTS ( SELECT 1 FROM public.experiment_phase_data epd JOIN public.experiment_phase_drafts epdr ON epd.phase_draft_id = epdr.id WHERE epd.id = phase_data_id AND epdr.user_id = auth.uid() ) ) WITH CHECK ( EXISTS ( SELECT 1 FROM public.experiment_phase_data epd JOIN public.experiment_phase_drafts epdr ON epd.phase_draft_id = epdr.id WHERE epd.id = phase_data_id AND epdr.user_id = auth.uid() ) ); CREATE POLICY "pecan_diameter_measurements_delete_policy" ON public.pecan_diameter_measurements FOR DELETE TO authenticated USING ( EXISTS ( SELECT 1 FROM public.experiment_phase_data epd JOIN public.experiment_phase_drafts epdr ON epd.phase_draft_id = epdr.id WHERE epd.id = phase_data_id AND epdr.user_id = auth.uid() AND epdr.status = 'draft' ) ); -- ============================================= -- 10. COMMENTS FOR DOCUMENTATION -- ============================================= COMMENT ON TABLE public.roles IS 'System roles for user access control'; COMMENT ON TABLE public.user_profiles IS 'Extended user profiles linked to auth.users'; COMMENT ON TABLE public.user_roles IS 'Many-to-many relationship between users and roles'; COMMENT ON TABLE public.experiment_phases IS 'Groups experiments into logical phases for better organization and navigation'; COMMENT ON TABLE public.experiments IS 'Stores experiment definitions for pecan processing with parameters and status tracking'; COMMENT ON TABLE public.experiment_repetitions IS 'Individual repetitions of experiment blueprints that can be scheduled and executed'; COMMENT ON TABLE public.experiment_phase_drafts IS 'Phase-specific draft records for experiment data entry with status tracking'; COMMENT ON TABLE public.experiment_phase_data IS 'Phase-specific measurement data for experiments'; COMMENT ON TABLE public.pecan_diameter_measurements IS 'Individual pecan diameter measurements (up to 10 per phase)';