Skip to content

Commit 686e045

Browse files
authored
Add hoster/client distribution metrics (#211)
* Add hoster/client distribution metrics * Optimize query
1 parent 93ce53b commit 686e045

File tree

2 files changed

+50
-0
lines changed

2 files changed

+50
-0
lines changed
Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,25 @@
1+
-- Returns client distribution for the specified date range
2+
3+
WITH clients_data AS (
4+
SELECT
5+
s.dim_name as client_name,
6+
SUM(h.value) as total_downloads
7+
FROM hosterPodcastMetrics h
8+
JOIN subdimensions s ON h.subdimension = s.dim_id
9+
WHERE h.account_id = @podcast_id
10+
AND h.dimension = 'clients'
11+
AND h.start = h.end
12+
AND h.start BETWEEN @start_date AND @end_date
13+
GROUP BY s.dim_id, s.dim_name
14+
HAVING total_downloads > 0
15+
)
16+
17+
SELECT
18+
client_name,
19+
total_downloads,
20+
ROUND(
21+
(total_downloads * 100.0 / SUM(total_downloads) OVER()),
22+
2
23+
) as percentage
24+
FROM clients_data
25+
ORDER BY total_downloads DESC;
Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,25 @@
1+
-- Returns platform distribution for the specified date range
2+
3+
WITH platforms_data AS (
4+
SELECT
5+
s.dim_name as platform_name,
6+
SUM(h.value) as total_downloads
7+
FROM hosterPodcastMetrics h
8+
JOIN subdimensions s ON h.subdimension = s.dim_id
9+
WHERE h.account_id = @podcast_id
10+
AND h.dimension = 'platforms'
11+
AND h.start = h.end
12+
AND h.start BETWEEN @start_date AND @end_date
13+
GROUP BY s.dim_id, s.dim_name
14+
HAVING total_downloads > 0
15+
)
16+
17+
SELECT
18+
platform_name,
19+
total_downloads,
20+
ROUND(
21+
(total_downloads * 100.0 / SUM(total_downloads) OVER()),
22+
2
23+
) as percentage
24+
FROM platforms_data
25+
ORDER BY total_downloads DESC;

0 commit comments

Comments
 (0)