-- Video progress tracking table -- Stores user's playback position for lessons and webinars CREATE TABLE IF NOT EXISTS video_progress ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, video_id TEXT NOT NULL, -- lesson_id or webinar/product_id video_type TEXT NOT NULL CHECK (video_type IN ('lesson', 'webinar')), last_position DECIMAL(10,2) NOT NULL DEFAULT 0, -- seconds total_duration DECIMAL(10,2), -- total video duration in seconds completed BOOLEAN DEFAULT FALSE, last_watched_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), UNIQUE(user_id, video_id, video_type) ); -- Indexes for fast queries CREATE INDEX IF NOT EXISTS idx_video_progress_user ON video_progress(user_id); CREATE INDEX IF NOT EXISTS idx_video_progress_user_type ON video_progress(user_id, video_type); CREATE INDEX IF NOT EXISTS idx_video_progress_completed ON video_progress(user_id, completed) WHERE completed = TRUE; -- Enable RLS ALTER TABLE video_progress ENABLE ROW LEVEL SECURITY; -- Drop existing policies if any DROP POLICY IF EXISTS "Users manage own progress" ON video_progress; DROP POLICY IF EXISTS "Service role full access" ON video_progress; -- Users can manage their own progress CREATE POLICY "Users manage own progress" ON video_progress FOR ALL TO authenticated USING (auth.uid() = user_id) WITH CHECK (auth.uid() = user_id); -- Service role has full access CREATE POLICY "Service role full access" ON video_progress FOR ALL TO service_role USING (true) WITH CHECK (true); -- Function to update updated_at timestamp CREATE OR REPLACE FUNCTION update_video_progress_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger to auto-update updated_at DROP TRIGGER IF EXISTS update_video_progress_updated_at ON video_progress; CREATE TRIGGER update_video_progress_updated_at BEFORE UPDATE ON video_progress FOR EACH ROW EXECUTE FUNCTION update_video_progress_updated_at();