Skip to content

Commit 4723a8e

Browse files
committed
Add SQL query to calculate lifetime downloads per episode for a given podcast
1 parent 32d4c51 commit 4723a8e

File tree

1 file changed

+58
-0
lines changed

1 file changed

+58
-0
lines changed
Lines changed: 58 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,58 @@
1+
-- Calculate lifetime downloads per episode for a given podcast (account_id)
2+
-- Lifetime downloads are calculated by summing all monthly download values per episode
3+
-- Monthly data has start = first day of month, end = last day of month
4+
-- +------------+------------+----------+---------------------+-----------+--------------------+
5+
-- | podcast_id | episode_id | ep_name | ep_release_date | hoster_id | lifetime_downloads |
6+
-- +------------+------------+----------+---------------------+-----------+--------------------+
7+
8+
9+
-- get subdimension id for downloads
10+
WITH download_subdimensions AS (
11+
SELECT
12+
dim_id, dim_name
13+
FROM
14+
subdimensions
15+
WHERE
16+
dim_name = 'complete'
17+
LIMIT 1
18+
),
19+
-- sum all monthly values per episode
20+
-- monthly rows start on the first of a month and the end is the last day of the month
21+
episode_lifetime_downloads AS (
22+
SELECT
23+
account_id,
24+
episode_id,
25+
hoster_id,
26+
dimension,
27+
subdimension,
28+
SUM(value) AS lifetime_downloads
29+
FROM
30+
hosterEpisodeMetrics
31+
WHERE
32+
account_id = @podcast_id
33+
AND dimension = 'downloads'
34+
AND subdimension = (SELECT dim_id FROM download_subdimensions)
35+
-- monthly rows start on the first of a month and the end is the last day of the month
36+
AND DAYOFMONTH(start) = 1 AND DATE(end) = LAST_DAY(start)
37+
GROUP BY
38+
account_id,
39+
episode_id,
40+
hoster_id,
41+
dimension,
42+
subdimension
43+
)
44+
45+
SELECT
46+
eld.account_id AS podcast_id,
47+
eld.episode_id,
48+
hmd.ep_name,
49+
hmd.ep_release_date,
50+
eld.hoster_id,
51+
eld.lifetime_downloads as lifetime_downloads
52+
FROM
53+
episode_lifetime_downloads eld
54+
JOIN
55+
hosterEpisodeMetadata hmd ON eld.account_id = hmd.account_id
56+
AND eld.episode_id = hmd.episode_id
57+
ORDER BY
58+
eld.lifetime_downloads DESC;

0 commit comments

Comments
 (0)