- Commented out all Supabase services to facilitate testing with Supabase CLI. - Updated README to include Supabase directory in project structure. - Adjusted documentation for migration paths in Supabase Docker Compose guide. - Enhanced docker-compose-reset.sh to explicitly remove Supabase volumes and wait for migrations to complete.
196 lines
7.9 KiB
PL/PgSQL
196 lines
7.9 KiB
PL/PgSQL
-- Views
|
|
-- This migration creates views for easier querying (must run last after all tables are created)
|
|
|
|
-- =============================================
|
|
-- 1. CREATE VIEWS FOR EASIER QUERYING
|
|
-- =============================================
|
|
|
|
-- View for experiments with all phase information
|
|
-- Note: Since phases are now per-repetition, this view shows phase data from the first repetition
|
|
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.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,
|
|
er.id as first_repetition_id,
|
|
er.repetition_number as first_repetition_number,
|
|
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.experiments e
|
|
LEFT JOIN public.experiment_phases ep ON e.phase_id = ep.id
|
|
LEFT JOIN LATERAL (
|
|
SELECT id, repetition_number
|
|
FROM public.experiment_repetitions
|
|
WHERE experiment_id = e.id
|
|
ORDER BY repetition_number
|
|
LIMIT 1
|
|
) er ON true
|
|
LEFT JOIN public.soaking s ON s.repetition_id = er.id
|
|
LEFT JOIN public.airdrying ad ON ad.repetition_id = er.id
|
|
LEFT JOIN public.cracking c ON c.repetition_id = er.id
|
|
LEFT JOIN public.machine_types mt ON c.machine_type_id = mt.id
|
|
LEFT JOIN public.shelling sh ON sh.repetition_id = er.id;
|
|
|
|
-- View for repetitions with phase information
|
|
CREATE OR REPLACE VIEW public.repetitions_with_phases AS
|
|
SELECT
|
|
er.id,
|
|
er.experiment_id,
|
|
er.repetition_number,
|
|
er.status,
|
|
er.created_at,
|
|
er.updated_at,
|
|
er.created_by,
|
|
e.experiment_number,
|
|
e.phase_id,
|
|
e.weight_per_repetition_lbs,
|
|
ep.name as phase_name,
|
|
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.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;
|
|
|
|
-- View for available conductors with their roles
|
|
CREATE OR REPLACE VIEW public.available_conductors AS
|
|
SELECT
|
|
ca.*,
|
|
up.email,
|
|
up.first_name,
|
|
up.last_name,
|
|
r.name as role_name
|
|
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';
|
|
|
|
-- =============================================
|
|
-- 2. GRANT PERMISSIONS FOR VIEWS
|
|
-- =============================================
|
|
|
|
GRANT SELECT ON public.experiments_with_phases TO authenticated;
|
|
GRANT SELECT ON public.repetitions_with_phases TO authenticated;
|
|
GRANT SELECT ON public.available_conductors TO authenticated;
|
|
|
|
-- =============================================
|
|
-- 3. COMMENTS FOR DOCUMENTATION
|
|
-- =============================================
|
|
|
|
COMMENT ON VIEW public.experiments_with_phases IS 'Comprehensive view of experiments with all phase information and timing details';
|
|
COMMENT ON VIEW public.repetitions_with_phases IS 'View of experiment repetitions with associated phase data';
|
|
COMMENT ON VIEW public.available_conductors IS 'View of currently available conductors with their profile information';
|
|
|
|
-- =============================================
|
|
-- 4. SAMPLE DATA FUNCTIONS (OPTIONAL)
|
|
-- =============================================
|
|
|
|
-- Function to create sample roles
|
|
CREATE OR REPLACE FUNCTION public.create_sample_roles()
|
|
RETURNS VOID AS $$
|
|
BEGIN
|
|
INSERT INTO public.roles (name, description) VALUES
|
|
('admin', 'System administrator with full access'),
|
|
('conductor', 'Experiment conductor with limited access'),
|
|
('researcher', 'Research staff with read-only access')
|
|
ON CONFLICT (name) DO NOTHING;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Function to create sample machine types
|
|
CREATE OR REPLACE FUNCTION public.create_sample_machine_types()
|
|
RETURNS VOID AS $$
|
|
BEGIN
|
|
INSERT INTO public.machine_types (name, description, created_by) VALUES
|
|
('JC Cracker', 'Johnson Cracker machine for pecan shelling', (SELECT id FROM public.user_profiles LIMIT 1)),
|
|
('Meyer Cracker', 'Meyer Cracker machine for pecan shelling', (SELECT id FROM public.user_profiles LIMIT 1))
|
|
ON CONFLICT (name) DO NOTHING;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Function to create sample experiment phases
|
|
CREATE OR REPLACE FUNCTION public.create_sample_experiment_phases()
|
|
RETURNS VOID AS $$
|
|
DECLARE
|
|
jc_cracker_id UUID;
|
|
meyer_cracker_id UUID;
|
|
BEGIN
|
|
-- Get machine type IDs
|
|
SELECT id INTO jc_cracker_id FROM public.machine_types WHERE name = 'JC Cracker';
|
|
SELECT id INTO meyer_cracker_id FROM public.machine_types WHERE name = 'Meyer Cracker';
|
|
|
|
INSERT INTO public.experiment_phases (name, description, has_soaking, has_airdrying, has_cracking, has_shelling, cracking_machine_type_id, created_by) VALUES
|
|
('Full Process - JC Cracker', 'Complete pecan processing with JC Cracker', true, true, true, true, jc_cracker_id, (SELECT id FROM public.user_profiles LIMIT 1)),
|
|
('Full Process - Meyer Cracker', 'Complete pecan processing with Meyer Cracker', true, true, true, true, meyer_cracker_id, (SELECT id FROM public.user_profiles LIMIT 1)),
|
|
('Cracking Only - JC Cracker', 'JC Cracker cracking process only', false, false, true, false, jc_cracker_id, (SELECT id FROM public.user_profiles LIMIT 1)),
|
|
('Cracking Only - Meyer Cracker', 'Meyer Cracker cracking process only', false, false, true, false, meyer_cracker_id, (SELECT id FROM public.user_profiles LIMIT 1))
|
|
ON CONFLICT (name) DO NOTHING;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- =============================================
|
|
-- 5. GRANT PERMISSIONS FOR SAMPLE DATA FUNCTIONS
|
|
-- =============================================
|
|
|
|
GRANT EXECUTE ON FUNCTION public.create_sample_roles() TO authenticated;
|
|
GRANT EXECUTE ON FUNCTION public.create_sample_machine_types() TO authenticated;
|
|
GRANT EXECUTE ON FUNCTION public.create_sample_experiment_phases() TO authenticated;
|
|
|