Files
thrilltrack-explorer/supabase/migrations/20251030222918_05a2e1ff-1eac-4824-8534-9bee48c3e8af.sql
2025-10-30 22:29:56 +00:00

87 lines
2.4 KiB
PL/PgSQL

-- Create a function to get recent changes across all entities in a single query
CREATE OR REPLACE FUNCTION get_recent_changes(limit_count INT DEFAULT 24)
RETURNS TABLE (
entity_type TEXT,
entity_id UUID,
entity_name TEXT,
entity_slug TEXT,
park_slug TEXT,
image_url TEXT,
change_type TEXT,
changed_at TIMESTAMPTZ,
changed_by_username TEXT,
changed_by_avatar TEXT,
change_reason TEXT
)
LANGUAGE plpgsql
STABLE
SECURITY DEFINER
SET search_path = public
AS $$
BEGIN
RETURN QUERY
SELECT * FROM (
-- Park versions
SELECT
'park'::TEXT as entity_type,
pv.park_id as entity_id,
pv.name as entity_name,
pv.slug as entity_slug,
NULL::TEXT as park_slug,
pv.card_image_url as image_url,
pv.change_type::TEXT as change_type,
pv.created_at as changed_at,
p.username as changed_by_username,
p.avatar_url as changed_by_avatar,
pv.change_reason as change_reason
FROM park_versions pv
LEFT JOIN profiles p ON p.user_id = pv.created_by
WHERE pv.is_current = true
UNION ALL
-- Ride versions with park slug
SELECT
'ride'::TEXT as entity_type,
rv.ride_id as entity_id,
rv.name as entity_name,
rv.slug as entity_slug,
parks.slug as park_slug,
rv.card_image_url as image_url,
rv.change_type::TEXT as change_type,
rv.created_at as changed_at,
p.username as changed_by_username,
p.avatar_url as changed_by_avatar,
rv.change_reason as change_reason
FROM ride_versions rv
LEFT JOIN profiles p ON p.user_id = rv.created_by
LEFT JOIN parks ON parks.id = rv.park_id
WHERE rv.is_current = true
UNION ALL
-- Company versions
SELECT
'company'::TEXT as entity_type,
cv.company_id as entity_id,
cv.name as entity_name,
cv.slug as entity_slug,
NULL::TEXT as park_slug,
cv.card_image_url as image_url,
cv.change_type::TEXT as change_type,
cv.created_at as changed_at,
p.username as changed_by_username,
p.avatar_url as changed_by_avatar,
cv.change_reason as change_reason
FROM company_versions cv
LEFT JOIN profiles p ON p.user_id = cv.created_by
WHERE cv.is_current = true
) combined
ORDER BY changed_at DESC
LIMIT limit_count;
END;
$$;
-- Grant execute permission to authenticated users
GRANT EXECUTE ON FUNCTION get_recent_changes(INT) TO authenticated;
GRANT EXECUTE ON FUNCTION get_recent_changes(INT) TO anon;