-- Migration: Add reposts, profile_layouts, and post_feed_scores tables -- Also adds engagement count columns to posts for feed algorithm -- ─── Engagement columns on posts ────────────────────────────────────────────── ALTER TABLE public.posts ADD COLUMN IF NOT EXISTS like_count INTEGER NOT NULL DEFAULT 0, ADD COLUMN IF NOT EXISTS comment_count INTEGER NOT NULL DEFAULT 0, ADD COLUMN IF NOT EXISTS share_count INTEGER NOT NULL DEFAULT 0, ADD COLUMN IF NOT EXISTS repost_count INTEGER NOT NULL DEFAULT 0, ADD COLUMN IF NOT EXISTS boost_count INTEGER NOT NULL DEFAULT 0, ADD COLUMN IF NOT EXISTS amplify_count INTEGER NOT NULL DEFAULT 0, ADD COLUMN IF NOT EXISTS view_count INTEGER NOT NULL DEFAULT 0, ADD COLUMN IF NOT EXISTS video_url TEXT; -- Backfill existing like/comment/view counts from post_metrics UPDATE public.posts p SET like_count = COALESCE(m.like_count, 0), comment_count = COALESCE(m.comment_count, 0), view_count = COALESCE(m.view_count, 0) FROM public.post_metrics m WHERE p.id = m.post_id; -- ─── Reposts ────────────────────────────────────────────────────────────────── CREATE TABLE IF NOT EXISTS public.reposts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), original_post_id UUID NOT NULL REFERENCES public.posts(id) ON DELETE CASCADE, author_id UUID NOT NULL REFERENCES public.profiles(id) ON DELETE CASCADE, type TEXT NOT NULL CHECK (type IN ('standard', 'quote', 'boost', 'amplify')), comment TEXT, metadata JSONB, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- One repost per type per user per post CREATE UNIQUE INDEX IF NOT EXISTS idx_reposts_unique ON public.reposts (original_post_id, author_id, type); CREATE INDEX IF NOT EXISTS idx_reposts_original_post_id ON public.reposts (original_post_id); CREATE INDEX IF NOT EXISTS idx_reposts_author_id ON public.reposts (author_id); CREATE INDEX IF NOT EXISTS idx_reposts_created_at ON public.reposts (created_at DESC); -- ─── Repost reports ─────────────────────────────────────────────────────────── CREATE TABLE IF NOT EXISTS public.repost_reports ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), repost_id UUID NOT NULL REFERENCES public.reposts(id) ON DELETE CASCADE, reporter_id UUID NOT NULL REFERENCES public.profiles(id) ON DELETE CASCADE, reason TEXT NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE (repost_id, reporter_id) ); -- ─── Profile widget layouts ─────────────────────────────────────────────────── CREATE TABLE IF NOT EXISTS public.profile_layouts ( user_id UUID PRIMARY KEY REFERENCES public.profiles(id) ON DELETE CASCADE, widgets JSONB NOT NULL DEFAULT '[]', theme VARCHAR(50) NOT NULL DEFAULT 'default', accent_color VARCHAR(20), banner_image_url TEXT, updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- ─── Post feed scores (feed algorithm) ─────────────────────────────────────── CREATE TABLE IF NOT EXISTS public.post_feed_scores ( post_id UUID PRIMARY KEY REFERENCES public.posts(id) ON DELETE CASCADE, score DOUBLE PRECISION NOT NULL DEFAULT 0, engagement_score DOUBLE PRECISION NOT NULL DEFAULT 0, quality_score DOUBLE PRECISION NOT NULL DEFAULT 0, recency_score DOUBLE PRECISION NOT NULL DEFAULT 0, network_score DOUBLE PRECISION NOT NULL DEFAULT 0, personalization DOUBLE PRECISION NOT NULL DEFAULT 0, updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_post_feed_scores_score ON public.post_feed_scores (score DESC);