-- rTrips module schema CREATE SCHEMA IF NOT EXISTS rtrips; CREATE TABLE IF NOT EXISTS rtrips.users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), did TEXT UNIQUE NOT NULL, username TEXT, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS rtrips.trips ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), title TEXT NOT NULL, slug TEXT UNIQUE NOT NULL, description TEXT, start_date DATE, end_date DATE, budget_total NUMERIC(12,2), budget_currency TEXT DEFAULT 'USD', status TEXT DEFAULT 'PLANNING' CHECK (status IN ('PLANNING','BOOKED','IN_PROGRESS','COMPLETED','CANCELLED')), created_by UUID REFERENCES rtrips.users(id), created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS rtrips.trip_collaborators ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), trip_id UUID NOT NULL REFERENCES rtrips.trips(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES rtrips.users(id) ON DELETE CASCADE, role TEXT NOT NULL DEFAULT 'MEMBER' CHECK (role IN ('OWNER','EDITOR','VIEWER','MEMBER')), joined_at TIMESTAMPTZ DEFAULT NOW(), UNIQUE(trip_id, user_id) ); CREATE TABLE IF NOT EXISTS rtrips.destinations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), trip_id UUID NOT NULL REFERENCES rtrips.trips(id) ON DELETE CASCADE, name TEXT NOT NULL, country TEXT, lat DOUBLE PRECISION, lng DOUBLE PRECISION, arrival_date DATE, departure_date DATE, notes TEXT, sort_order INT DEFAULT 0, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS rtrips.itinerary_items ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), trip_id UUID NOT NULL REFERENCES rtrips.trips(id) ON DELETE CASCADE, destination_id UUID REFERENCES rtrips.destinations(id) ON DELETE SET NULL, title TEXT NOT NULL, category TEXT DEFAULT 'ACTIVITY' CHECK (category IN ('FLIGHT','TRANSPORT','ACCOMMODATION','ACTIVITY','MEAL','FREE_TIME','OTHER')), date DATE, start_time TIME, end_time TIME, notes TEXT, sort_order INT DEFAULT 0, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS rtrips.bookings ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), trip_id UUID NOT NULL REFERENCES rtrips.trips(id) ON DELETE CASCADE, type TEXT DEFAULT 'OTHER' CHECK (type IN ('FLIGHT','HOTEL','CAR_RENTAL','TRAIN','BUS','FERRY','ACTIVITY','RESTAURANT','OTHER')), provider TEXT, confirmation_number TEXT, cost NUMERIC(12,2), currency TEXT DEFAULT 'USD', start_date DATE, end_date DATE, status TEXT DEFAULT 'PENDING' CHECK (status IN ('PENDING','CONFIRMED','CANCELLED')), notes TEXT, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS rtrips.expenses ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), trip_id UUID NOT NULL REFERENCES rtrips.trips(id) ON DELETE CASCADE, paid_by UUID REFERENCES rtrips.users(id), description TEXT NOT NULL, amount NUMERIC(12,2) NOT NULL, currency TEXT DEFAULT 'USD', category TEXT DEFAULT 'OTHER' CHECK (category IN ('FOOD','TRANSPORT','ACCOMMODATION','ACTIVITIES','SHOPPING','OTHER')), date DATE, split_type TEXT DEFAULT 'EQUAL' CHECK (split_type IN ('EQUAL','CUSTOM','INDIVIDUAL')), created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS rtrips.packing_items ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), trip_id UUID NOT NULL REFERENCES rtrips.trips(id) ON DELETE CASCADE, added_by UUID REFERENCES rtrips.users(id), name TEXT NOT NULL, category TEXT DEFAULT 'GENERAL', packed BOOLEAN DEFAULT FALSE, quantity INT DEFAULT 1, sort_order INT DEFAULT 0, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_rtrips_destinations ON rtrips.destinations(trip_id, sort_order); CREATE INDEX IF NOT EXISTS idx_rtrips_itinerary ON rtrips.itinerary_items(trip_id, date, sort_order); CREATE INDEX IF NOT EXISTS idx_rtrips_bookings ON rtrips.bookings(trip_id, start_date); CREATE INDEX IF NOT EXISTS idx_rtrips_expenses ON rtrips.expenses(trip_id, date DESC); CREATE INDEX IF NOT EXISTS idx_rtrips_packing ON rtrips.packing_items(trip_id, category, sort_order); CREATE INDEX IF NOT EXISTS idx_rtrips_collaborators ON rtrips.trip_collaborators(user_id);