mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-22 16:51:13 -05:00
129 lines
3.9 KiB
PL/PgSQL
129 lines
3.9 KiB
PL/PgSQL
-- Add sort_order column to user_ride_credits
|
|
ALTER TABLE user_ride_credits
|
|
ADD COLUMN sort_order INTEGER;
|
|
|
|
-- Create unique index to prevent duplicate positions per user
|
|
CREATE UNIQUE INDEX idx_user_ride_credits_sort_order
|
|
ON user_ride_credits(user_id, sort_order)
|
|
WHERE sort_order IS NOT NULL;
|
|
|
|
-- Function to reorder a ride credit to a new position
|
|
CREATE OR REPLACE FUNCTION reorder_ride_credit(
|
|
p_credit_id UUID,
|
|
p_new_position INTEGER
|
|
) RETURNS VOID AS $$
|
|
DECLARE
|
|
v_user_id UUID;
|
|
v_old_position INTEGER;
|
|
v_max_position INTEGER;
|
|
BEGIN
|
|
-- Get credit details
|
|
SELECT user_id, sort_order INTO v_user_id, v_old_position
|
|
FROM user_ride_credits
|
|
WHERE id = p_credit_id;
|
|
|
|
IF v_user_id IS NULL THEN
|
|
RAISE EXCEPTION 'Credit not found';
|
|
END IF;
|
|
|
|
-- Lock user's credits to prevent race conditions
|
|
PERFORM 1 FROM user_ride_credits WHERE user_id = v_user_id FOR UPDATE;
|
|
|
|
-- Get max position for validation
|
|
SELECT COALESCE(MAX(sort_order), 0) INTO v_max_position
|
|
FROM user_ride_credits
|
|
WHERE user_id = v_user_id;
|
|
|
|
-- Validate new position
|
|
IF p_new_position < 1 OR p_new_position > v_max_position THEN
|
|
RAISE EXCEPTION 'Invalid position. Must be between 1 and %', v_max_position;
|
|
END IF;
|
|
|
|
-- If position unchanged, do nothing
|
|
IF v_old_position = p_new_position THEN
|
|
RETURN;
|
|
END IF;
|
|
|
|
-- Temporarily set to NULL to avoid unique constraint violation
|
|
UPDATE user_ride_credits SET sort_order = NULL WHERE id = p_credit_id;
|
|
|
|
IF p_new_position < v_old_position THEN
|
|
-- Moving up: shift down items between new and old position
|
|
UPDATE user_ride_credits
|
|
SET sort_order = sort_order + 1
|
|
WHERE user_id = v_user_id
|
|
AND sort_order >= p_new_position
|
|
AND sort_order < v_old_position;
|
|
ELSE
|
|
-- Moving down: shift up items between old and new position
|
|
UPDATE user_ride_credits
|
|
SET sort_order = sort_order - 1
|
|
WHERE user_id = v_user_id
|
|
AND sort_order > v_old_position
|
|
AND sort_order <= p_new_position;
|
|
END IF;
|
|
|
|
-- Set new position
|
|
UPDATE user_ride_credits SET sort_order = p_new_position WHERE id = p_credit_id;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public;
|
|
|
|
-- Function to backfill sort_order for existing credits
|
|
CREATE OR REPLACE FUNCTION backfill_sort_orders()
|
|
RETURNS void AS $$
|
|
DECLARE
|
|
user_record RECORD;
|
|
credit_record RECORD;
|
|
position_counter INTEGER;
|
|
BEGIN
|
|
FOR user_record IN SELECT DISTINCT user_id FROM user_ride_credits LOOP
|
|
position_counter := 0;
|
|
|
|
FOR credit_record IN
|
|
SELECT id
|
|
FROM user_ride_credits
|
|
WHERE user_id = user_record.user_id
|
|
ORDER BY first_ride_date ASC NULLS LAST, created_at ASC
|
|
LOOP
|
|
position_counter := position_counter + 1;
|
|
UPDATE user_ride_credits
|
|
SET sort_order = position_counter
|
|
WHERE id = credit_record.id;
|
|
END LOOP;
|
|
END LOOP;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public;
|
|
|
|
-- Run backfill to populate existing data
|
|
SELECT backfill_sort_orders();
|
|
|
|
-- Update auto-review trigger to assign position at end
|
|
CREATE OR REPLACE FUNCTION auto_add_ride_credit_on_review()
|
|
RETURNS trigger AS $$
|
|
DECLARE
|
|
v_next_position INTEGER;
|
|
BEGIN
|
|
IF NEW.ride_id IS NOT NULL THEN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM public.user_ride_credits
|
|
WHERE user_id = NEW.user_id AND ride_id = NEW.ride_id
|
|
) THEN
|
|
-- Get next position
|
|
SELECT COALESCE(MAX(sort_order), 0) + 1 INTO v_next_position
|
|
FROM public.user_ride_credits
|
|
WHERE user_id = NEW.user_id;
|
|
|
|
-- Insert with position at end
|
|
INSERT INTO public.user_ride_credits (
|
|
user_id, ride_id, first_ride_date, ride_count, sort_order
|
|
) VALUES (
|
|
NEW.user_id, NEW.ride_id, NEW.visit_date, 1, v_next_position
|
|
);
|
|
|
|
RAISE NOTICE 'Auto-added ride credit for user % on ride %', NEW.user_id, NEW.ride_id;
|
|
END IF;
|
|
END IF;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public; |