- 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.
194 lines
7.1 KiB
PL/PgSQL
194 lines
7.1 KiB
PL/PgSQL
-- Conductor Availability
|
|
-- This migration creates the conductor availability table
|
|
|
|
-- =============================================
|
|
-- 1. 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. INDEXES FOR PERFORMANCE
|
|
-- =============================================
|
|
|
|
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);
|
|
|
|
-- =============================================
|
|
-- 3. 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 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;
|
|
|
|
-- =============================================
|
|
-- 4. 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 to prevent overlapping availabilities
|
|
CREATE TRIGGER trigger_check_availability_overlap
|
|
BEFORE INSERT OR UPDATE ON public.conductor_availability
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.check_availability_overlap();
|
|
|
|
-- =============================================
|
|
-- 5. GRANT PERMISSIONS
|
|
-- =============================================
|
|
|
|
GRANT ALL ON public.conductor_availability TO authenticated;
|
|
|
|
-- =============================================
|
|
-- 6. ENABLE ROW LEVEL SECURITY
|
|
-- =============================================
|
|
|
|
ALTER TABLE public.conductor_availability ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- =============================================
|
|
-- 7. CREATE RLS 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()
|
|
);
|
|
|
|
|
|
|
|
|