-- Function: Get comprehensive database statistics CREATE OR REPLACE FUNCTION public.get_database_statistics() RETURNS jsonb LANGUAGE plpgsql STABLE SECURITY DEFINER SET search_path = public AS $$ DECLARE v_stats jsonb; v_parks_total integer; v_parks_active integer; v_parks_historical integer; v_parks_7d integer; v_parks_30d integer; v_rides_total integer; v_rides_active integer; v_rides_historical integer; v_rides_7d integer; v_rides_30d integer; v_companies_total integer; v_manufacturers integer; v_operators integer; v_designers integer; v_companies_7d integer; v_companies_30d integer; v_ride_models_total integer; v_ride_models_7d integer; v_ride_models_30d integer; v_locations_total integer; v_timeline_events_total integer; v_photos_total integer; v_photos_7d integer; v_photos_30d integer; v_users_total integer; v_users_active_30d integer; v_submissions_pending integer; v_submissions_approved integer; v_submissions_rejected integer; BEGIN -- Parks statistics SELECT COUNT(*) INTO v_parks_total FROM parks; SELECT COUNT(*) INTO v_parks_active FROM parks WHERE status = 'operating'; SELECT COUNT(*) INTO v_parks_historical FROM parks WHERE status IN ('closed', 'historical'); SELECT COUNT(*) INTO v_parks_7d FROM parks WHERE created_at > NOW() - INTERVAL '7 days'; SELECT COUNT(*) INTO v_parks_30d FROM parks WHERE created_at > NOW() - INTERVAL '30 days'; -- Rides statistics SELECT COUNT(*) INTO v_rides_total FROM rides; SELECT COUNT(*) INTO v_rides_active FROM rides WHERE status = 'operating'; SELECT COUNT(*) INTO v_rides_historical FROM rides WHERE status IN ('closed', 'removed', 'relocated'); SELECT COUNT(*) INTO v_rides_7d FROM rides WHERE created_at > NOW() - INTERVAL '7 days'; SELECT COUNT(*) INTO v_rides_30d FROM rides WHERE created_at > NOW() - INTERVAL '30 days'; -- Companies statistics SELECT COUNT(*) INTO v_companies_total FROM companies; SELECT COUNT(*) INTO v_manufacturers FROM companies WHERE company_type = 'manufacturer'; SELECT COUNT(*) INTO v_operators FROM companies WHERE company_type = 'operator'; SELECT COUNT(*) INTO v_designers FROM companies WHERE company_type = 'designer'; SELECT COUNT(*) INTO v_companies_7d FROM companies WHERE created_at > NOW() - INTERVAL '7 days'; SELECT COUNT(*) INTO v_companies_30d FROM companies WHERE created_at > NOW() - INTERVAL '30 days'; -- Ride models statistics SELECT COUNT(*) INTO v_ride_models_total FROM ride_models; SELECT COUNT(*) INTO v_ride_models_7d FROM ride_models WHERE created_at > NOW() - INTERVAL '7 days'; SELECT COUNT(*) INTO v_ride_models_30d FROM ride_models WHERE created_at > NOW() - INTERVAL '30 days'; -- Locations statistics SELECT COUNT(*) INTO v_locations_total FROM locations; -- Timeline events statistics SELECT COUNT(*) INTO v_timeline_events_total FROM entity_timeline_events; -- Photos statistics SELECT COUNT(*) INTO v_photos_total FROM entity_photos; SELECT COUNT(*) INTO v_photos_7d FROM entity_photos WHERE uploaded_at > NOW() - INTERVAL '7 days'; SELECT COUNT(*) INTO v_photos_30d FROM entity_photos WHERE uploaded_at > NOW() - INTERVAL '30 days'; -- Users statistics SELECT COUNT(*) INTO v_users_total FROM profiles; SELECT COUNT(*) INTO v_users_active_30d FROM profiles WHERE updated_at > NOW() - INTERVAL '30 days'; -- Submissions statistics SELECT COUNT(*) INTO v_submissions_pending FROM content_submissions WHERE status = 'pending'; SELECT COUNT(*) INTO v_submissions_approved FROM content_submissions WHERE status = 'approved'; SELECT COUNT(*) INTO v_submissions_rejected FROM content_submissions WHERE status = 'rejected'; -- Build result JSON v_stats := jsonb_build_object( 'parks', jsonb_build_object( 'total', v_parks_total, 'active', v_parks_active, 'historical', v_parks_historical, 'added_7d', v_parks_7d, 'added_30d', v_parks_30d ), 'rides', jsonb_build_object( 'total', v_rides_total, 'active', v_rides_active, 'historical', v_rides_historical, 'added_7d', v_rides_7d, 'added_30d', v_rides_30d ), 'companies', jsonb_build_object( 'total', v_companies_total, 'manufacturers', v_manufacturers, 'operators', v_operators, 'designers', v_designers, 'added_7d', v_companies_7d, 'added_30d', v_companies_30d ), 'ride_models', jsonb_build_object( 'total', v_ride_models_total, 'added_7d', v_ride_models_7d, 'added_30d', v_ride_models_30d ), 'locations', jsonb_build_object( 'total', v_locations_total ), 'timeline_events', jsonb_build_object( 'total', v_timeline_events_total ), 'photos', jsonb_build_object( 'total', v_photos_total, 'added_7d', v_photos_7d, 'added_30d', v_photos_30d ), 'users', jsonb_build_object( 'total', v_users_total, 'active_30d', v_users_active_30d ), 'submissions', jsonb_build_object( 'pending', v_submissions_pending, 'approved', v_submissions_approved, 'rejected', v_submissions_rejected ) ); RETURN v_stats; END; $$; -- Function: Get recent additions across all entity types CREATE OR REPLACE FUNCTION public.get_recent_additions(limit_count integer DEFAULT 50) RETURNS TABLE( entity_id uuid, entity_type text, entity_name text, entity_slug text, park_slug text, image_url text, created_at timestamptz, created_by_id uuid, created_by_username text, created_by_avatar text ) LANGUAGE plpgsql STABLE SECURITY DEFINER SET search_path = public AS $$ BEGIN RETURN QUERY SELECT * FROM ( -- Parks SELECT p.id as entity_id, 'park'::text as entity_type, p.name as entity_name, p.slug as entity_slug, NULL::text as park_slug, p.card_image_url as image_url, p.created_at, p.created_by as created_by_id, prof.username as created_by_username, prof.avatar_url as created_by_avatar FROM parks p LEFT JOIN profiles prof ON prof.user_id = p.created_by UNION ALL -- Rides SELECT r.id as entity_id, 'ride'::text as entity_type, r.name as entity_name, r.slug as entity_slug, pk.slug as park_slug, r.card_image_url as image_url, r.created_at, r.created_by as created_by_id, prof.username as created_by_username, prof.avatar_url as created_by_avatar FROM rides r LEFT JOIN parks pk ON pk.id = r.park_id LEFT JOIN profiles prof ON prof.user_id = r.created_by UNION ALL -- Companies SELECT c.id as entity_id, 'company'::text as entity_type, c.name as entity_name, c.slug as entity_slug, NULL::text as park_slug, c.card_image_url as image_url, c.created_at, c.created_by as created_by_id, prof.username as created_by_username, prof.avatar_url as created_by_avatar FROM companies c LEFT JOIN profiles prof ON prof.user_id = c.created_by UNION ALL -- Ride Models SELECT rm.id as entity_id, 'ride_model'::text as entity_type, rm.name as entity_name, rm.slug as entity_slug, NULL::text as park_slug, rm.card_image_url as image_url, rm.created_at, rm.created_by as created_by_id, prof.username as created_by_username, prof.avatar_url as created_by_avatar FROM ride_models rm LEFT JOIN profiles prof ON prof.user_id = rm.created_by UNION ALL -- Locations SELECT l.id as entity_id, 'location'::text as entity_type, COALESCE(l.city || ', ' || l.country, l.country, 'Location') as entity_name, NULL::text as entity_slug, NULL::text as park_slug, NULL::text as image_url, l.created_at, NULL::uuid as created_by_id, NULL::text as created_by_username, NULL::text as created_by_avatar FROM locations l UNION ALL -- Timeline Events SELECT te.id as entity_id, 'timeline_event'::text as entity_type, te.event_title as entity_name, NULL::text as entity_slug, NULL::text as park_slug, NULL::text as image_url, te.created_at, te.created_by as created_by_id, prof.username as created_by_username, prof.avatar_url as created_by_avatar FROM entity_timeline_events te LEFT JOIN profiles prof ON prof.user_id = te.created_by UNION ALL -- Photos SELECT ep.id as entity_id, 'photo'::text as entity_type, COALESCE(ep.title, 'Photo') as entity_name, NULL::text as entity_slug, NULL::text as park_slug, ep.cloudflare_url as image_url, ep.uploaded_at as created_at, ep.uploaded_by as created_by_id, prof.username as created_by_username, prof.avatar_url as created_by_avatar FROM entity_photos ep LEFT JOIN profiles prof ON prof.user_id = ep.uploaded_by ) combined ORDER BY created_at DESC LIMIT limit_count; END; $$;