Files
thrilltrack-explorer/supabase/migrations/20251028183015_3606a4e9-5807-4d64-989e-3b623ba9f5a9.sql
2025-10-28 18:33:32 +00:00

54 lines
1.6 KiB
PL/PgSQL

-- Add ticket number system to contact submissions
-- Create sequence for ticket numbers starting at 100000
CREATE SEQUENCE IF NOT EXISTS contact_ticket_number_seq START 100000;
-- Add ticket_number column with unique constraint
ALTER TABLE public.contact_submissions
ADD COLUMN IF NOT EXISTS ticket_number TEXT UNIQUE;
-- Create function to generate ticket number in format TW-XXXXXX
CREATE OR REPLACE FUNCTION generate_ticket_number()
RETURNS TEXT AS $$
BEGIN
RETURN 'TW-' || LPAD(nextval('contact_ticket_number_seq')::TEXT, 6, '0');
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Create function to auto-set ticket number on insert
CREATE OR REPLACE FUNCTION set_ticket_number()
RETURNS TRIGGER AS $$
BEGIN
IF NEW.ticket_number IS NULL THEN
NEW.ticket_number := generate_ticket_number();
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Add trigger to auto-generate ticket numbers
DROP TRIGGER IF EXISTS set_ticket_number_trigger ON public.contact_submissions;
CREATE TRIGGER set_ticket_number_trigger
BEFORE INSERT ON public.contact_submissions
FOR EACH ROW
EXECUTE FUNCTION set_ticket_number();
-- Backfill existing submissions with ticket numbers based on creation order
DO $$
DECLARE
rec RECORD;
BEGIN
FOR rec IN
SELECT id
FROM public.contact_submissions
WHERE ticket_number IS NULL
ORDER BY created_at ASC
LOOP
UPDATE public.contact_submissions
SET ticket_number = generate_ticket_number()
WHERE id = rec.id;
END LOOP;
END $$;
-- Add index for ticket_number lookups
CREATE INDEX IF NOT EXISTS idx_contact_submissions_ticket_number
ON public.contact_submissions(ticket_number);