mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 07:11:12 -05:00
Refactor: Optimize recent changes query
This commit is contained in:
@@ -22,124 +22,27 @@ export function useHomepageRecentChanges(enabled = true) {
|
||||
return useQuery({
|
||||
queryKey: queryKeys.homepage.recentChanges(),
|
||||
queryFn: async () => {
|
||||
// Fetch recent park versions
|
||||
const { data: parkVersions } = await supabase
|
||||
.from('park_versions')
|
||||
.select(`
|
||||
park_id,
|
||||
name,
|
||||
slug,
|
||||
card_image_url,
|
||||
change_type,
|
||||
created_at,
|
||||
created_by,
|
||||
change_reason,
|
||||
profiles:created_by(username, avatar_url)
|
||||
`)
|
||||
.eq('is_current', true)
|
||||
.order('created_at', { ascending: false })
|
||||
.limit(8);
|
||||
|
||||
// Fetch recent ride versions
|
||||
const { data: rideVersions } = await supabase
|
||||
.from('ride_versions')
|
||||
.select(`
|
||||
ride_id,
|
||||
name,
|
||||
slug,
|
||||
card_image_url,
|
||||
change_type,
|
||||
created_at,
|
||||
created_by,
|
||||
change_reason,
|
||||
park_id,
|
||||
profiles:created_by(username, avatar_url)
|
||||
`)
|
||||
.eq('is_current', true)
|
||||
.order('created_at', { ascending: false })
|
||||
.limit(8);
|
||||
|
||||
// Fetch park slugs for rides
|
||||
const parkIds = rideVersions?.map(rv => rv.park_id).filter(Boolean) || [];
|
||||
const { data: parks } = parkIds.length > 0
|
||||
? await supabase
|
||||
.from('parks')
|
||||
.select('id, slug')
|
||||
.in('id', parkIds)
|
||||
: { data: [] };
|
||||
|
||||
const parkSlugMap = new Map<string, string>(
|
||||
(parks || []).map(p => [p.id, p.slug])
|
||||
);
|
||||
|
||||
// Fetch recent company versions
|
||||
const { data: companyVersions } = await supabase
|
||||
.from('company_versions')
|
||||
.select(`
|
||||
company_id,
|
||||
name,
|
||||
slug,
|
||||
card_image_url,
|
||||
change_type,
|
||||
created_at,
|
||||
created_by,
|
||||
change_reason,
|
||||
profiles:created_by(username, avatar_url)
|
||||
`)
|
||||
.eq('is_current', true)
|
||||
.order('created_at', { ascending: false })
|
||||
.limit(8);
|
||||
|
||||
// Combine and sort all changes
|
||||
const changes: RecentChange[] = [
|
||||
...(parkVersions || []).map(pv => ({
|
||||
id: pv.park_id,
|
||||
name: pv.name,
|
||||
type: 'park' as const,
|
||||
slug: pv.slug,
|
||||
imageUrl: pv.card_image_url,
|
||||
changeType: pv.change_type,
|
||||
changedAt: pv.created_at,
|
||||
changedBy: pv.profiles ? {
|
||||
username: pv.profiles.username,
|
||||
avatarUrl: pv.profiles.avatar_url
|
||||
} : undefined,
|
||||
changeReason: pv.change_reason
|
||||
})),
|
||||
...(rideVersions || []).map(rv => ({
|
||||
id: rv.ride_id,
|
||||
name: rv.name,
|
||||
type: 'ride' as const,
|
||||
slug: rv.slug,
|
||||
parkSlug: rv.park_id ? (parkSlugMap.get(rv.park_id) || undefined) : undefined,
|
||||
imageUrl: rv.card_image_url,
|
||||
changeType: rv.change_type,
|
||||
changedAt: rv.created_at,
|
||||
changedBy: rv.profiles ? {
|
||||
username: rv.profiles.username,
|
||||
avatarUrl: rv.profiles.avatar_url
|
||||
} : undefined,
|
||||
changeReason: rv.change_reason
|
||||
})),
|
||||
...(companyVersions || []).map(cv => ({
|
||||
id: cv.company_id,
|
||||
name: cv.name,
|
||||
type: 'company' as const,
|
||||
slug: cv.slug,
|
||||
imageUrl: cv.card_image_url,
|
||||
changeType: cv.change_type,
|
||||
changedAt: cv.created_at,
|
||||
changedBy: cv.profiles ? {
|
||||
username: cv.profiles.username,
|
||||
avatarUrl: cv.profiles.avatar_url
|
||||
} : undefined,
|
||||
changeReason: cv.change_reason
|
||||
}))
|
||||
];
|
||||
|
||||
return changes
|
||||
.sort((a, b) => new Date(b.changedAt).getTime() - new Date(a.changedAt).getTime())
|
||||
.slice(0, 24);
|
||||
// Use the new database function to get all changes in a single query
|
||||
const { data, error } = await supabase.rpc('get_recent_changes', { limit_count: 24 });
|
||||
|
||||
if (error) throw error;
|
||||
|
||||
// Transform the database response to match our interface
|
||||
return (data || []).map((item: any) => ({
|
||||
id: item.entity_id,
|
||||
name: item.entity_name,
|
||||
type: item.entity_type as 'park' | 'ride' | 'company',
|
||||
slug: item.entity_slug,
|
||||
parkSlug: item.park_slug || undefined,
|
||||
imageUrl: item.image_url || undefined,
|
||||
changeType: item.change_type,
|
||||
changedAt: item.changed_at,
|
||||
changedBy: item.changed_by_username ? {
|
||||
username: item.changed_by_username,
|
||||
avatarUrl: item.changed_by_avatar || undefined
|
||||
} : undefined,
|
||||
changeReason: item.change_reason || undefined
|
||||
})) as RecentChange[];
|
||||
},
|
||||
enabled,
|
||||
staleTime: 5 * 60 * 1000,
|
||||
|
||||
@@ -4619,6 +4619,22 @@ export type Database = {
|
||||
user_agent: string
|
||||
}[]
|
||||
}
|
||||
get_recent_changes: {
|
||||
Args: { limit_count?: number }
|
||||
Returns: {
|
||||
change_reason: string
|
||||
change_type: string
|
||||
changed_at: string
|
||||
changed_by_avatar: string
|
||||
changed_by_username: string
|
||||
entity_id: string
|
||||
entity_name: string
|
||||
entity_slug: string
|
||||
entity_type: string
|
||||
image_url: string
|
||||
park_slug: string
|
||||
}[]
|
||||
}
|
||||
get_submission_item_dependencies: {
|
||||
Args: { item_id: string }
|
||||
Returns: {
|
||||
|
||||
@@ -0,0 +1,87 @@
|
||||
-- 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;
|
||||
Reference in New Issue
Block a user