|
| 1 | +-- Top episodes performance based on hoster data only |
| 2 | +-- Uses daily data (start = end) after episode release date |
| 3 | +-- Aggregates downloads from hoster episode metrics |
| 4 | + |
| 5 | +WITH download_subdimensions AS ( |
| 6 | + SELECT |
| 7 | + dim_id |
| 8 | + FROM |
| 9 | + subdimensions |
| 10 | + WHERE |
| 11 | + dim_name = 'complete' |
| 12 | + LIMIT 1 |
| 13 | +), |
| 14 | +hoster_episode_performance AS ( |
| 15 | + SELECT |
| 16 | + hem.account_id, |
| 17 | + hem.episode_id, |
| 18 | + hmd.ep_name, |
| 19 | + hmd.ep_release_date, |
| 20 | + hem.value as downloads, |
| 21 | + DATEDIFF(hem.start, hmd.ep_release_date) AS day_since_release |
| 22 | + FROM |
| 23 | + hosterEpisodeMetrics hem |
| 24 | + JOIN |
| 25 | + hosterEpisodeMetadata hmd ON hem.episode_id = hmd.episode_id |
| 26 | + AND hem.account_id = hmd.account_id |
| 27 | + WHERE |
| 28 | + hem.account_id = @podcast_id |
| 29 | + AND hem.dimension = 'downloads' |
| 30 | + AND hem.subdimension = (SELECT dim_id FROM download_subdimensions) |
| 31 | + AND hem.start = hem.end -- daily data only |
| 32 | + AND hem.start >= hmd.ep_release_date -- only data after release |
| 33 | +), |
| 34 | +average_downloads AS ( |
| 35 | + -- Calculate the average downloads per day since release |
| 36 | + SELECT |
| 37 | + account_id, |
| 38 | + day_since_release, |
| 39 | + FLOOR(AVG(downloads)) AS avg_downloads |
| 40 | + FROM hoster_episode_performance |
| 41 | + WHERE account_id = @podcast_id |
| 42 | + GROUP BY account_id, day_since_release |
| 43 | +), |
| 44 | +ranked_episodes AS ( |
| 45 | + -- Rank episodes by total downloads per account |
| 46 | + SELECT |
| 47 | + account_id, |
| 48 | + episode_id, |
| 49 | + SUM(downloads) AS total_downloads, |
| 50 | + RANK() OVER (PARTITION BY account_id ORDER BY SUM(downloads) DESC) AS ep_rank |
| 51 | + FROM hoster_episode_performance |
| 52 | + WHERE account_id = @podcast_id |
| 53 | + GROUP BY account_id, episode_id |
| 54 | +), |
| 55 | +top_episodes AS ( |
| 56 | + -- Filter to top 10 episodes per account |
| 57 | + SELECT * |
| 58 | + FROM ranked_episodes |
| 59 | + WHERE ep_rank <= 10 |
| 60 | +) |
| 61 | +SELECT |
| 62 | + dl.account_id, |
| 63 | + ed.ep_name, |
| 64 | + dl.episode_id, |
| 65 | + dl.day_since_release, |
| 66 | + dl.downloads as total_downloads, |
| 67 | + ad.avg_downloads |
| 68 | +FROM hoster_episode_performance dl |
| 69 | +JOIN top_episodes te |
| 70 | + ON dl.account_id = te.account_id |
| 71 | + AND dl.episode_id = te.episode_id |
| 72 | +JOIN average_downloads ad |
| 73 | + ON dl.account_id = ad.account_id |
| 74 | + AND dl.day_since_release = ad.day_since_release |
| 75 | +JOIN hosterEpisodeMetadata ed |
| 76 | + ON dl.account_id = ed.account_id |
| 77 | + AND dl.episode_id = ed.episode_id |
| 78 | +WHERE dl.account_id = @podcast_id |
0 commit comments