Refactor experiment management and update data structures

- Renamed columns in the experimental run sheet CSV for clarity.
- Updated the ExperimentForm component to include new fields for weight per repetition and additional parameters specific to Meyer Cracker experiments.
- Enhanced the data entry logic to handle new experiment phases and machine types.
- Refactored repetition scheduling logic to use scheduled_date instead of schedule_status for better clarity in status representation.
- Improved the user interface for displaying experiment phases and their associated statuses.
- Removed outdated seed data and updated database migration scripts to reflect the new schema changes.
This commit is contained in:
salirezav
2025-09-24 14:27:28 -04:00
parent 08538c87c3
commit aaeb164a32
33 changed files with 6489 additions and 1123 deletions

View File

@@ -0,0 +1,785 @@
-- 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)';

View File

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

View File

@@ -0,0 +1,474 @@
-- Migration: Restructure experiment phases and add machine types
-- This migration restructures the experiment system to support separate phase tables
-- and machine-specific parameters
-- =============================================
-- 1. MACHINE TYPES
-- =============================================
-- Create machine types table
CREATE TABLE IF NOT EXISTS public.machine_types (
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)
);
-- Machine types will be inserted in seed.sql after user profiles are created
-- =============================================
-- 2. UPDATE EXPERIMENT_PHASES TABLE
-- =============================================
-- Add phase selection columns to experiment_phases
ALTER TABLE public.experiment_phases
ADD COLUMN IF NOT EXISTS has_soaking BOOLEAN NOT NULL DEFAULT false,
ADD COLUMN IF NOT EXISTS has_airdrying BOOLEAN NOT NULL DEFAULT false,
ADD COLUMN IF NOT EXISTS has_cracking BOOLEAN NOT NULL DEFAULT false,
ADD COLUMN IF NOT EXISTS has_shelling BOOLEAN NOT NULL DEFAULT false;
-- Add constraint to ensure at least one phase is selected
ALTER TABLE public.experiment_phases
ADD CONSTRAINT check_at_least_one_phase
CHECK (has_soaking = true OR has_airdrying = true OR has_cracking = true OR has_shelling = true);
-- =============================================
-- 3. CREATE PHASE-SPECIFIC TABLES
-- =============================================
-- Create 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)
);
-- Create 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)
);
-- Create 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)
);
-- Create 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)
);
-- =============================================
-- 4. MACHINE-SPECIFIC PARAMETER TABLES
-- =============================================
-- 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)
);
-- 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 CHECK (jig_displacement_inches >= 0),
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)
);
-- =============================================
-- 5. UPDATE EXPERIMENTS TABLE
-- =============================================
-- Add weight_per_repetition column
ALTER TABLE public.experiments
ADD COLUMN IF NOT EXISTS weight_per_repetition_lbs DOUBLE PRECISION NOT NULL DEFAULT 0 CHECK (weight_per_repetition_lbs > 0);
-- Remove phase-specific parameters (these will be moved to phase tables)
-- Note: We'll keep these columns for now to avoid data loss, but they should be deprecated
-- Make old columns nullable to support new schema experiments
ALTER TABLE public.experiments
ALTER COLUMN soaking_duration_hr DROP NOT NULL,
ALTER COLUMN air_drying_time_min DROP NOT NULL,
ALTER COLUMN plate_contact_frequency_hz DROP NOT NULL,
ALTER COLUMN throughput_rate_pecans_sec DROP NOT NULL,
ALTER COLUMN crush_amount_in DROP NOT NULL,
ALTER COLUMN entry_exit_height_diff_in DROP NOT NULL;
-- =============================================
-- 6. ADD FOREIGN KEY CONSTRAINTS
-- =============================================
-- 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;
-- =============================================
-- 7. CREATE INDEXES FOR PERFORMANCE
-- =============================================
-- Create indexes for better query performance
CREATE INDEX IF NOT EXISTS idx_soaking_experiment_id ON public.soaking(experiment_id);
CREATE INDEX IF NOT EXISTS idx_soaking_repetition_id ON public.soaking(repetition_id);
CREATE INDEX IF NOT EXISTS idx_airdrying_experiment_id ON public.airdrying(experiment_id);
CREATE INDEX IF NOT EXISTS idx_airdrying_repetition_id ON public.airdrying(repetition_id);
CREATE INDEX IF NOT EXISTS idx_cracking_experiment_id ON public.cracking(experiment_id);
CREATE INDEX IF NOT EXISTS idx_cracking_repetition_id ON public.cracking(repetition_id);
CREATE INDEX IF NOT EXISTS idx_cracking_machine_type_id ON public.cracking(machine_type_id);
CREATE INDEX IF NOT EXISTS idx_shelling_experiment_id ON public.shelling(experiment_id);
CREATE INDEX IF NOT EXISTS idx_shelling_repetition_id ON public.shelling(repetition_id);
-- =============================================
-- 8. CREATE TRIGGERS 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;
-- Trigger for soaking scheduled end time
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();
-- 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;
-- Trigger for airdrying 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();
-- 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;
-- Trigger for airdrying scheduled start 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();
-- 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;
-- Trigger for cracking 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();
-- =============================================
-- 9. CREATE VIEWS FOR EASIER QUERYING
-- =============================================
-- View for experiments with all phase information
CREATE OR REPLACE VIEW public.experiments_with_phases AS
SELECT
e.id,
e.experiment_number,
e.reps_required,
e.weight_per_repetition_lbs,
e.results_status,
e.completion_status,
e.phase_id,
e.soaking_id,
e.airdrying_id,
e.cracking_id,
e.shelling_id,
e.created_at,
e.updated_at,
e.created_by,
ep.name as phase_name,
ep.description as phase_description,
ep.has_soaking,
ep.has_airdrying,
ep.has_cracking,
ep.has_shelling,
s.scheduled_start_time as soaking_scheduled_start,
s.actual_start_time as soaking_actual_start,
s.soaking_duration_minutes,
s.scheduled_end_time as soaking_scheduled_end,
s.actual_end_time as soaking_actual_end,
ad.scheduled_start_time as airdrying_scheduled_start,
ad.actual_start_time as airdrying_actual_start,
ad.duration_minutes as airdrying_duration,
ad.scheduled_end_time as airdrying_scheduled_end,
ad.actual_end_time as airdrying_actual_end,
c.scheduled_start_time as cracking_scheduled_start,
c.actual_start_time as cracking_actual_start,
c.actual_end_time as cracking_actual_end,
mt.name as machine_type_name,
sh.scheduled_start_time as shelling_scheduled_start,
sh.actual_start_time as shelling_actual_start,
sh.actual_end_time as shelling_actual_end
FROM public.experiments e
LEFT JOIN public.experiment_phases ep ON e.phase_id = ep.id
LEFT JOIN public.soaking s ON e.soaking_id = s.id
LEFT JOIN public.airdrying ad ON e.airdrying_id = ad.id
LEFT JOIN public.cracking c ON e.cracking_id = c.id
LEFT JOIN public.machine_types mt ON c.machine_type_id = mt.id
LEFT JOIN public.shelling sh ON e.shelling_id = sh.id;
-- View for repetitions with phase information
CREATE OR REPLACE VIEW public.repetitions_with_phases AS
SELECT
er.*,
e.experiment_number,
e.weight_per_repetition_lbs,
ep.name as phase_name,
ep.has_soaking,
ep.has_airdrying,
ep.has_cracking,
ep.has_shelling,
s.id as soaking_id,
s.scheduled_start_time as soaking_scheduled_start,
s.actual_start_time as soaking_actual_start,
s.soaking_duration_minutes,
s.scheduled_end_time as soaking_scheduled_end,
s.actual_end_time as soaking_actual_end,
ad.id as airdrying_id,
ad.scheduled_start_time as airdrying_scheduled_start,
ad.actual_start_time as airdrying_actual_start,
ad.duration_minutes as airdrying_duration,
ad.scheduled_end_time as airdrying_scheduled_end,
ad.actual_end_time as airdrying_actual_end,
c.id as cracking_id,
c.scheduled_start_time as cracking_scheduled_start,
c.actual_start_time as cracking_actual_start,
c.actual_end_time as cracking_actual_end,
mt.name as machine_type_name,
sh.id as shelling_id,
sh.scheduled_start_time as shelling_scheduled_start,
sh.actual_start_time as shelling_actual_start,
sh.actual_end_time as shelling_actual_end
FROM public.experiment_repetitions er
JOIN public.experiments e ON er.experiment_id = e.id
LEFT JOIN public.experiment_phases ep ON e.phase_id = ep.id
LEFT JOIN public.soaking s ON er.id = s.repetition_id
LEFT JOIN public.airdrying ad ON er.id = ad.repetition_id
LEFT JOIN public.cracking c ON er.id = c.repetition_id
LEFT JOIN public.machine_types mt ON c.machine_type_id = mt.id
LEFT JOIN public.shelling sh ON er.id = sh.repetition_id;
-- =============================================
-- 10. GRANT PERMISSIONS
-- =============================================
-- Grant permissions for new tables
GRANT ALL ON public.machine_types TO authenticated;
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;
GRANT ALL ON public.jc_cracker_parameters TO authenticated;
GRANT ALL ON public.meyer_cracker_parameters TO authenticated;
-- Grant permissions for views
GRANT SELECT ON public.experiments_with_phases TO authenticated;
GRANT SELECT ON public.repetitions_with_phases TO authenticated;
-- =============================================
-- 11. UPDATE RLS POLICIES
-- =============================================
-- Enable RLS on new tables
ALTER TABLE public.machine_types 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;
ALTER TABLE public.jc_cracker_parameters ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.meyer_cracker_parameters ENABLE ROW LEVEL SECURITY;
-- Create RLS policies for machine_types (read-only for all authenticated users)
CREATE POLICY "Machine types are viewable by authenticated users" ON public.machine_types
FOR SELECT USING (auth.role() = 'authenticated');
-- Create RLS policies for phase tables (similar to experiments)
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');
-- Similar policies for other phase tables
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');
-- RLS policies for machine parameter tables
CREATE POLICY "JC Cracker parameters are viewable by authenticated users" ON public.jc_cracker_parameters
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "JC Cracker parameters are insertable by authenticated users" ON public.jc_cracker_parameters
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "JC Cracker parameters are updatable by authenticated users" ON public.jc_cracker_parameters
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "JC Cracker parameters are deletable by authenticated users" ON public.jc_cracker_parameters
FOR DELETE USING (auth.role() = 'authenticated');
CREATE POLICY "Meyer Cracker parameters are viewable by authenticated users" ON public.meyer_cracker_parameters
FOR SELECT USING (auth.role() = 'authenticated');
CREATE POLICY "Meyer Cracker parameters are insertable by authenticated users" ON public.meyer_cracker_parameters
FOR INSERT WITH CHECK (auth.role() = 'authenticated');
CREATE POLICY "Meyer Cracker parameters are updatable by authenticated users" ON public.meyer_cracker_parameters
FOR UPDATE USING (auth.role() = 'authenticated');
CREATE POLICY "Meyer Cracker parameters are deletable by authenticated users" ON public.meyer_cracker_parameters
FOR DELETE USING (auth.role() = 'authenticated');

View File

@@ -0,0 +1,49 @@
-- Add password reset function for admin use
-- This migration adds a function to reset user passwords back to the default "password123"
-- Function to reset user password (admin only)
CREATE OR REPLACE FUNCTION public.reset_user_password(
target_user_id UUID
)
RETURNS JSON AS $$
DECLARE
user_email TEXT;
result JSON;
BEGIN
-- Only admins can reset passwords
IF NOT public.is_admin() THEN
RAISE EXCEPTION 'Only administrators can reset user passwords';
END IF;
-- Check if target user exists
SELECT email INTO user_email
FROM public.user_profiles
WHERE id = target_user_id;
IF user_email IS NULL THEN
RAISE EXCEPTION 'User not found';
END IF;
-- Update the password in auth.users table
UPDATE auth.users
SET
encrypted_password = crypt('password123', gen_salt('bf')),
updated_at = NOW()
WHERE id = target_user_id;
-- Return result
result := json_build_object(
'user_id', target_user_id,
'email', user_email,
'new_password', 'password123',
'reset_at', NOW()
);
RETURN result;
EXCEPTION
WHEN OTHERS THEN
RAISE;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;

View File

@@ -0,0 +1,12 @@
-- Add first_name and last_name fields to user_profiles table
-- This migration adds name fields to store user's first and last names
-- Add first_name and last_name columns to user_profiles table
ALTER TABLE public.user_profiles
ADD COLUMN first_name TEXT,
ADD COLUMN last_name TEXT;
-- Add comments for documentation
COMMENT ON COLUMN public.user_profiles.first_name IS 'User first name';
COMMENT ON COLUMN public.user_profiles.last_name IS 'User last name';

View File

@@ -0,0 +1,62 @@
-- Add change password function for users
-- This migration adds a function to allow users to change their own password
-- Function to change user password (user can only change their own password)
CREATE OR REPLACE FUNCTION public.change_user_password(
current_password TEXT,
new_password TEXT
)
RETURNS JSON AS $$
DECLARE
user_id UUID;
user_email TEXT;
result JSON;
BEGIN
-- Get current user ID
user_id := auth.uid();
IF user_id IS NULL THEN
RAISE EXCEPTION 'User not authenticated';
END IF;
-- Get user email
SELECT email INTO user_email
FROM public.user_profiles
WHERE id = user_id;
IF user_email IS NULL THEN
RAISE EXCEPTION 'User profile not found';
END IF;
-- Verify current password
IF NOT EXISTS (
SELECT 1
FROM auth.users
WHERE id = user_id
AND encrypted_password = crypt(current_password, encrypted_password)
) THEN
RAISE EXCEPTION 'Current password is incorrect';
END IF;
-- Update the password in auth.users table
UPDATE auth.users
SET
encrypted_password = crypt(new_password, gen_salt('bf')),
updated_at = NOW()
WHERE id = user_id;
-- Return result
result := json_build_object(
'user_id', user_id,
'email', user_email,
'password_changed_at', NOW()
);
RETURN result;
EXCEPTION
WHEN OTHERS THEN
RAISE;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;