Files
thrilltrack-explorer/supabase/migrations/20251010155048_7be05bad-b276-4b15-9546-7ff5b9f9bcd9.sql
2025-10-10 15:53:56 +00:00

121 lines
4.2 KiB
PL/PgSQL

-- Phase 1: Create view tracking infrastructure
-- Create entity_page_views table for tracking page views
CREATE TABLE entity_page_views (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
entity_type text NOT NULL CHECK (entity_type IN ('park', 'ride', 'company')),
entity_id uuid NOT NULL,
viewed_at timestamp with time zone DEFAULT now(),
session_hash text,
created_at timestamp with time zone DEFAULT now()
);
-- Create index for fast trending queries
CREATE INDEX idx_entity_views_trending ON entity_page_views(entity_type, entity_id, viewed_at DESC);
CREATE INDEX idx_entity_views_by_type ON entity_page_views(entity_type, viewed_at DESC);
-- Enable RLS
ALTER TABLE entity_page_views ENABLE ROW LEVEL SECURITY;
-- Policy: Allow inserts from anyone (tracking is anonymous)
CREATE POLICY "Anyone can track page views" ON entity_page_views
FOR INSERT WITH CHECK (true);
-- Policy: Only moderators can read analytics
CREATE POLICY "Moderators can read analytics" ON entity_page_views
FOR SELECT USING (is_moderator(auth.uid()));
-- Add view count columns to parks
ALTER TABLE parks ADD COLUMN IF NOT EXISTS view_count_7d integer DEFAULT 0;
ALTER TABLE parks ADD COLUMN IF NOT EXISTS view_count_30d integer DEFAULT 0;
ALTER TABLE parks ADD COLUMN IF NOT EXISTS view_count_all integer DEFAULT 0;
-- Add view count columns to rides
ALTER TABLE rides ADD COLUMN IF NOT EXISTS view_count_7d integer DEFAULT 0;
ALTER TABLE rides ADD COLUMN IF NOT EXISTS view_count_30d integer DEFAULT 0;
ALTER TABLE rides ADD COLUMN IF NOT EXISTS view_count_all integer DEFAULT 0;
-- Add view count columns to companies
ALTER TABLE companies ADD COLUMN IF NOT EXISTS view_count_7d integer DEFAULT 0;
ALTER TABLE companies ADD COLUMN IF NOT EXISTS view_count_30d integer DEFAULT 0;
ALTER TABLE companies ADD COLUMN IF NOT EXISTS view_count_all integer DEFAULT 0;
-- Create indexes for sorting by view count
CREATE INDEX idx_parks_view_count_30d ON parks(view_count_30d DESC);
CREATE INDEX idx_rides_view_count_30d ON rides(view_count_30d DESC);
CREATE INDEX idx_companies_view_count_30d ON companies(view_count_30d DESC);
-- Create function to update view counts (runs daily via cron)
CREATE OR REPLACE FUNCTION update_entity_view_counts()
RETURNS void
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO 'public'
AS $$
BEGIN
-- Update parks view counts
UPDATE parks p SET
view_count_7d = (
SELECT COUNT(*) FROM entity_page_views
WHERE entity_type = 'park' AND entity_id = p.id
AND viewed_at >= NOW() - INTERVAL '7 days'
),
view_count_30d = (
SELECT COUNT(*) FROM entity_page_views
WHERE entity_type = 'park' AND entity_id = p.id
AND viewed_at >= NOW() - INTERVAL '30 days'
),
view_count_all = (
SELECT COUNT(*) FROM entity_page_views
WHERE entity_type = 'park' AND entity_id = p.id
);
-- Update rides view counts
UPDATE rides r SET
view_count_7d = (
SELECT COUNT(*) FROM entity_page_views
WHERE entity_type = 'ride' AND entity_id = r.id
AND viewed_at >= NOW() - INTERVAL '7 days'
),
view_count_30d = (
SELECT COUNT(*) FROM entity_page_views
WHERE entity_type = 'ride' AND entity_id = r.id
AND viewed_at >= NOW() - INTERVAL '30 days'
),
view_count_all = (
SELECT COUNT(*) FROM entity_page_views
WHERE entity_type = 'ride' AND entity_id = r.id
);
-- Update companies view counts
UPDATE companies c SET
view_count_7d = (
SELECT COUNT(*) FROM entity_page_views
WHERE entity_type = 'company' AND entity_id = c.id
AND viewed_at >= NOW() - INTERVAL '7 days'
),
view_count_30d = (
SELECT COUNT(*) FROM entity_page_views
WHERE entity_type = 'company' AND entity_id = c.id
AND viewed_at >= NOW() - INTERVAL '30 days'
),
view_count_all = (
SELECT COUNT(*) FROM entity_page_views
WHERE entity_type = 'company' AND entity_id = c.id
);
END;
$$;
-- Create cleanup function to prevent database bloat
CREATE OR REPLACE FUNCTION cleanup_old_page_views()
RETURNS void
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO 'public'
AS $$
BEGIN
-- Delete views older than 90 days (keep recent data only)
DELETE FROM entity_page_views
WHERE viewed_at < NOW() - INTERVAL '90 days';
END;
$$;