Files
thrilltrack-explorer/supabase/migrations/20251111170746_c102113c-c8a8-477a-9559-f2934da4ef07.sql
gpt-engineer-app[bot] 947964482f Enhance admin stats dashboard
Add data quality metrics, growth trends visualization, entity comparison views, and automated health checks to the AdminDatabaseStats dashboard, including new TS types, hooks, UI components, and integrated tabbed layout.
2025-11-11 17:11:11 +00:00

407 lines
12 KiB
PL/PgSQL

-- Enhanced Database Analytics Functions
-- 1. Get Entity Growth Trends (time-series data)
CREATE OR REPLACE FUNCTION get_entity_growth_trends(
days_back integer DEFAULT 90,
granularity text DEFAULT 'daily'
)
RETURNS TABLE (
period text,
parks_added integer,
rides_added integer,
companies_added integer,
ride_models_added integer,
photos_added integer,
total_added integer
)
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
interval_format text;
trunc_format text;
BEGIN
-- Set format based on granularity
CASE granularity
WHEN 'daily' THEN
interval_format := '1 day';
trunc_format := 'day';
WHEN 'weekly' THEN
interval_format := '1 week';
trunc_format := 'week';
WHEN 'monthly' THEN
interval_format := '1 month';
trunc_format := 'month';
ELSE
interval_format := '1 day';
trunc_format := 'day';
END CASE;
RETURN QUERY
WITH date_series AS (
SELECT generate_series(
date_trunc(trunc_format, CURRENT_DATE - (days_back || ' days')::interval),
date_trunc(trunc_format, CURRENT_DATE),
interval_format::interval
)::date AS period_date
),
parks_data AS (
SELECT
date_trunc(trunc_format, created_at)::date AS period_date,
COUNT(*)::integer AS count
FROM parks
WHERE created_at >= CURRENT_DATE - (days_back || ' days')::interval
GROUP BY date_trunc(trunc_format, created_at)::date
),
rides_data AS (
SELECT
date_trunc(trunc_format, created_at)::date AS period_date,
COUNT(*)::integer AS count
FROM rides
WHERE created_at >= CURRENT_DATE - (days_back || ' days')::interval
GROUP BY date_trunc(trunc_format, created_at)::date
),
companies_data AS (
SELECT
date_trunc(trunc_format, created_at)::date AS period_date,
COUNT(*)::integer AS count
FROM companies
WHERE created_at >= CURRENT_DATE - (days_back || ' days')::interval
GROUP BY date_trunc(trunc_format, created_at)::date
),
models_data AS (
SELECT
date_trunc(trunc_format, created_at)::date AS period_date,
COUNT(*)::integer AS count
FROM ride_models
WHERE created_at >= CURRENT_DATE - (days_back || ' days')::interval
GROUP BY date_trunc(trunc_format, created_at)::date
),
photos_data AS (
SELECT
date_trunc(trunc_format, created_at)::date AS period_date,
COUNT(*)::integer AS count
FROM entity_photos
WHERE created_at >= CURRENT_DATE - (days_back || ' days')::interval
GROUP BY date_trunc(trunc_format, created_at)::date
)
SELECT
ds.period_date::text,
COALESCE(p.count, 0),
COALESCE(r.count, 0),
COALESCE(c.count, 0),
COALESCE(m.count, 0),
COALESCE(ph.count, 0),
COALESCE(p.count, 0) + COALESCE(r.count, 0) + COALESCE(c.count, 0) + COALESCE(m.count, 0) + COALESCE(ph.count, 0)
FROM date_series ds
LEFT JOIN parks_data p ON ds.period_date = p.period_date
LEFT JOIN rides_data r ON ds.period_date = r.period_date
LEFT JOIN companies_data c ON ds.period_date = c.period_date
LEFT JOIN models_data m ON ds.period_date = m.period_date
LEFT JOIN photos_data ph ON ds.period_date = ph.period_date
ORDER BY ds.period_date;
END;
$$;
-- 2. Get Entity Comparisons (rankings)
CREATE OR REPLACE FUNCTION get_entity_comparisons()
RETURNS jsonb
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
result jsonb;
BEGIN
SELECT jsonb_build_object(
'top_parks_by_rides', (
SELECT jsonb_agg(row_to_json(t))
FROM (
SELECT
p.name AS park_name,
p.slug AS park_slug,
COUNT(DISTINCT r.id)::integer AS ride_count,
COUNT(DISTINCT ep.id)::integer AS photo_count
FROM parks p
LEFT JOIN rides r ON r.park_id = p.id
LEFT JOIN entity_photos ep ON ep.entity_id = p.id AND ep.entity_type = 'park'
GROUP BY p.id, p.name, p.slug
ORDER BY COUNT(DISTINCT r.id) DESC
LIMIT 20
) t
),
'top_manufacturers', (
SELECT jsonb_agg(row_to_json(t))
FROM (
SELECT
c.name AS manufacturer_name,
c.slug,
COUNT(DISTINCT r.id)::integer AS ride_count,
COUNT(DISTINCT rm.id)::integer AS model_count
FROM companies c
LEFT JOIN rides r ON r.manufacturer_id = c.id
LEFT JOIN ride_models rm ON rm.manufacturer_id = c.id
WHERE c.is_manufacturer = true
GROUP BY c.id, c.name, c.slug
ORDER BY COUNT(DISTINCT r.id) DESC
LIMIT 20
) t
),
'top_operators', (
SELECT jsonb_agg(row_to_json(t))
FROM (
SELECT
c.name AS operator_name,
c.slug,
COUNT(DISTINCT p.id)::integer AS park_count,
COUNT(DISTINCT r.id)::integer AS ride_count
FROM companies c
LEFT JOIN parks p ON p.operator_id = c.id
LEFT JOIN rides r ON r.park_id = p.id
WHERE c.is_operator = true
GROUP BY c.id, c.name, c.slug
ORDER BY COUNT(DISTINCT p.id) DESC
LIMIT 20
) t
),
'top_designers', (
SELECT jsonb_agg(row_to_json(t))
FROM (
SELECT
c.name AS designer_name,
c.slug,
COUNT(DISTINCT r.id)::integer AS ride_count
FROM companies c
LEFT JOIN rides r ON r.designer_id = c.id
WHERE c.is_designer = true
GROUP BY c.id, c.name, c.slug
ORDER BY COUNT(DISTINCT r.id) DESC
LIMIT 20
) t
),
'top_parks_by_photos', (
SELECT jsonb_agg(row_to_json(t))
FROM (
SELECT
p.name AS park_name,
p.slug AS park_slug,
COUNT(DISTINCT ep.id)::integer AS photo_count
FROM parks p
LEFT JOIN entity_photos ep ON ep.entity_id = p.id AND ep.entity_type = 'park'
GROUP BY p.id, p.name, p.slug
ORDER BY COUNT(DISTINCT ep.id) DESC
LIMIT 20
) t
),
'top_rides_by_photos', (
SELECT jsonb_agg(row_to_json(t))
FROM (
SELECT
r.name AS ride_name,
r.slug AS ride_slug,
p.slug AS park_slug,
COUNT(DISTINCT ep.id)::integer AS photo_count
FROM rides r
LEFT JOIN parks p ON r.park_id = p.id
LEFT JOIN entity_photos ep ON ep.entity_id = r.id AND ep.entity_type = 'ride'
GROUP BY r.id, r.name, r.slug, p.slug
ORDER BY COUNT(DISTINCT ep.id) DESC
LIMIT 20
) t
)
) INTO result;
RETURN result;
END;
$$;
-- 3. Check Database Health (automated health checks)
CREATE OR REPLACE FUNCTION check_database_health()
RETURNS jsonb
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
issues jsonb := '[]'::jsonb;
critical_count integer := 0;
warning_count integer := 0;
info_count integer := 0;
overall_score integer;
issue jsonb;
BEGIN
-- CRITICAL: Parks missing critical fields
SELECT jsonb_build_object(
'severity', 'critical',
'category', 'missing_critical_fields',
'count', COUNT(*),
'entity_ids', jsonb_agg(id),
'description', 'Parks missing status, park_type, or location',
'suggested_action', 'Add missing critical information to these parks'
) INTO issue
FROM parks
WHERE status IS NULL OR park_type IS NULL OR location_id IS NULL;
IF (issue->>'count')::integer > 0 THEN
issues := issues || jsonb_build_array(issue);
critical_count := critical_count + (issue->>'count')::integer;
END IF;
-- CRITICAL: Rides missing critical fields
SELECT jsonb_build_object(
'severity', 'critical',
'category', 'missing_critical_fields',
'count', COUNT(*),
'entity_ids', jsonb_agg(id),
'description', 'Rides missing park, category, or status',
'suggested_action', 'Add missing critical information to these rides'
) INTO issue
FROM rides
WHERE park_id IS NULL OR category IS NULL OR status IS NULL;
IF (issue->>'count')::integer > 0 THEN
issues := issues || jsonb_build_array(issue);
critical_count := critical_count + (issue->>'count')::integer;
END IF;
-- CRITICAL: Data integrity - opening after closing
SELECT jsonb_build_object(
'severity', 'critical',
'category', 'data_integrity',
'count', COUNT(*),
'entity_ids', jsonb_agg(id),
'description', 'Parks with opening date after closing date',
'suggested_action', 'Fix date ranges for these parks'
) INTO issue
FROM parks
WHERE opening_date IS NOT NULL
AND closing_date IS NOT NULL
AND opening_date > closing_date;
IF (issue->>'count')::integer > 0 THEN
issues := issues || jsonb_build_array(issue);
critical_count := critical_count + (issue->>'count')::integer;
END IF;
-- WARNING: Outdated entities
SELECT jsonb_build_object(
'severity', 'warning',
'category', 'outdated_information',
'count', COUNT(*),
'entity_ids', jsonb_agg(id),
'description', 'Parks not updated in 365+ days',
'suggested_action', 'Review and update these parks with current information'
) INTO issue
FROM parks
WHERE updated_at < CURRENT_DATE - INTERVAL '365 days';
IF (issue->>'count')::integer > 0 THEN
issues := issues || jsonb_build_array(issue);
warning_count := warning_count + (issue->>'count')::integer;
END IF;
-- WARNING: Missing descriptions
SELECT jsonb_build_object(
'severity', 'warning',
'category', 'missing_descriptions',
'count', COUNT(*),
'entity_ids', jsonb_agg(id),
'description', 'Parks without descriptions or with very short ones',
'suggested_action', 'Add detailed descriptions to improve content quality'
) INTO issue
FROM parks
WHERE description IS NULL OR LENGTH(description) < 50;
IF (issue->>'count')::integer > 0 THEN
issues := issues || jsonb_build_array(issue);
warning_count := warning_count + (issue->>'count')::integer;
END IF;
-- WARNING: Missing images
SELECT jsonb_build_object(
'severity', 'warning',
'category', 'missing_images',
'count', COUNT(*),
'entity_ids', jsonb_agg(p.id),
'description', 'Parks without banner or card images',
'suggested_action', 'Upload images to improve visual appeal'
) INTO issue
FROM parks p
LEFT JOIN entity_photos ep ON ep.entity_id = p.id AND ep.entity_type = 'park'
WHERE ep.id IS NULL;
IF (issue->>'count')::integer > 0 THEN
issues := issues || jsonb_build_array(issue);
warning_count := warning_count + (issue->>'count')::integer;
END IF;
-- WARNING: Historical entities without closing dates
SELECT jsonb_build_object(
'severity', 'warning',
'category', 'incomplete_historical_data',
'count', COUNT(*),
'entity_ids', jsonb_agg(id),
'description', 'Historical parks without closing dates',
'suggested_action', 'Add closing dates for proper historical tracking'
) INTO issue
FROM parks
WHERE status = 'closed' AND closing_date IS NULL;
IF (issue->>'count')::integer > 0 THEN
issues := issues || jsonb_build_array(issue);
warning_count := warning_count + (issue->>'count')::integer;
END IF;
-- INFO: Low content parks
SELECT jsonb_build_object(
'severity', 'info',
'category', 'content_gaps',
'count', COUNT(*),
'entity_ids', jsonb_agg(p.id),
'description', 'Parks with fewer than 3 rides documented',
'suggested_action', 'Consider adding more rides to improve park coverage'
) INTO issue
FROM parks p
LEFT JOIN rides r ON r.park_id = p.id
GROUP BY p.id
HAVING COUNT(r.id) < 3 AND COUNT(r.id) > 0;
IF (issue->>'count')::integer > 0 THEN
issues := issues || jsonb_build_array(issue);
info_count := info_count + (issue->>'count')::integer;
END IF;
-- INFO: Manufacturers with low content
SELECT jsonb_build_object(
'severity', 'info',
'category', 'content_gaps',
'count', COUNT(*),
'entity_ids', jsonb_agg(c.id),
'description', 'Manufacturers with fewer than 5 rides documented',
'suggested_action', 'Consider documenting more rides from these manufacturers'
) INTO issue
FROM companies c
LEFT JOIN rides r ON r.manufacturer_id = c.id
WHERE c.is_manufacturer = true
GROUP BY c.id
HAVING COUNT(r.id) < 5 AND COUNT(r.id) > 0;
IF (issue->>'count')::integer > 0 THEN
issues := issues || jsonb_build_array(issue);
info_count := info_count + (issue->>'count')::integer;
END IF;
-- Calculate overall health score (0-100)
overall_score := GREATEST(0, 100 - (critical_count * 5) - (warning_count * 2) - (info_count * 1));
RETURN jsonb_build_object(
'overall_score', overall_score,
'critical_issues', critical_count,
'warning_issues', warning_count,
'info_issues', info_count,
'issues', issues,
'checked_at', NOW()
);
END;
$$;