ukyoutubeproject
gonzalo project youtube
The Head of Marketing wants to find out who the top YouTubers are in 2024 to decide on which YouTubers would be best to run marketing campaigns throughout the rest of the year.
To create a dashboard that provides insights into the top UK YouTubers in 2024 that includes their
This will help the marketing team make informed decisions about which YouTubers to collaborate with for their marketing campaigns.
As the Head of Marketing, I want to use a dashboard that analyses YouTube channel data in the UK .
This dashboard should allow me to identify the top performing channels based on metrics like subscriber base and average views.
With this information, I can make more informed decisions about which Youtubers are right to collaborate with, and therefore maximize how effective each marketing campaign is.
We need data on the top UK YouTubers in 2024 that includes their
total videos uploaded
To understand what it should contain, we need to figure out what questions we need the dashboard to answer:
For now, these are some of the questions we need to answer, this may change as we progress down our analysis.
Tool | Purpose |
---|---|
Excel | Exploring the data |
SQL Server | Cleaning, testing, and analyzing the data |
Power BI | Visualizing the data via interactive dashboards |
GitHub | Hosting the project documentation and version control |
Mokkup AI | Designing the wireframe/mockup of the dashboard |
This is the stage where you have a scan of what’s in the data, errors, inconcsistencies, bugs, weird and corrupted characters etc
The aim is to refine our dataset to ensure it is structured and ready for analysis.
The cleaned data should meet the following criteria and constraints:
Below is a table outlining the constraints on our cleaned dataset:
Property | Description |
---|---|
Number of Rows | 100 |
Number of Columns | 4 |
And here is a tabular representation of the expected schema for the clean data:
Column Name | Data Type | Nullable |
---|---|---|
channel_name | VARCHAR | NO |
total_subscribers | INTEGER | NO |
total_views | INTEGER | NO |
total_videos | INTEGER | NO |
/*
# 1. Select the required columns
# 2. Extract the channel name from the 'NOMBRE' column
*/
-- 1.
SELECT
SUBSTRING(NOMBRE, 1, CHARINDEX('@', NOMBRE) -1) AS channel_name, -- 2.
total_subscribers,
total_views,
total_videos
FROM
top_uk_youtubers_2024
/*
# 1. Create a view to store the transformed data
# 2. Cast the extracted channel name as VARCHAR(100)
# 3. Select the required columns from the top_uk_youtubers_2024 SQL table
*/
-- 1.
CREATE VIEW view_uk_youtubers_2024 AS
-- 2.
SELECT
CAST(SUBSTRING(NOMBRE, 1, CHARINDEX('@', NOMBRE) -1) AS VARCHAR(100)) AS channel_name, -- 2.
total_subscribers,
total_views,
total_videos
-- 3.
FROM
top_uk_youtubers_2024
Here are the data quality tests conducted:
/*
# Count the total number of records (or rows) are in the SQL view
*/
SELECT
COUNT(*) AS no_of_rows
FROM
view_uk_youtubers_2024;
/*
# Count the total number of columns (or fields) are in the SQL view
*/
SELECT
COUNT(*) AS column_count
FROM
INFORMATION_SCHEMA.COLUMNS
WHERE
TABLE_NAME = 'view_uk_youtubers_2024'
/*
# Check the data types of each column from the view by checking the INFORMATION SCHEMA view
*/
-- 1.
SELECT
COLUMN_NAME,
DATA_TYPE
FROM
INFORMATION_SCHEMA.COLUMNS
WHERE
TABLE_NAME = 'view_uk_youtubers_2024';
/*
# 1. Check for duplicate rows in the view
# 2. Group by the channel name
# 3. Filter for groups with more than one row
*/
-- 1.
SELECT
channel_name,
COUNT(*) AS duplicate_count
FROM
view_uk_youtubers_2024
-- 2.
GROUP BY
channel_name
-- 3.
HAVING
COUNT(*) > 1;
This shows the Top UK Youtubers in 2024 so far.
Total Subscribers (M) =
VAR million = 1000000
VAR sumOfSubscribers = SUM(view_uk_youtubers_2024[total_subscribers])
VAR totalSubscribers = DIVIDE(sumOfSubscribers,million)
RETURN totalSubscribers
Total Views (B) =
VAR billion = 1000000000
VAR sumOfTotalViews = SUM(view_uk_youtubers_2024[total_views])
VAR totalViews = ROUND(sumOfTotalViews / billion, 2)
RETURN totalViews
Total Videos =
VAR totalVideos = SUM(view_uk_youtubers_2024[total_videos])
RETURN totalVideos
Average Views per Video (M) =
VAR sumOfTotalViews = SUM(view_uk_youtubers_2024[total_views])
VAR sumOfTotalVideos = SUM(view_uk_youtubers_2024[total_videos])
VAR avgViewsPerVideo = DIVIDE(sumOfTotalViews,sumOfTotalVideos, BLANK())
VAR finalAvgViewsPerVideo = DIVIDE(avgViewsPerVideo, 1000000, BLANK())
RETURN finalAvgViewsPerVideo
Subscriber Engagement Rate =
VAR sumOfTotalSubscribers = SUM(view_uk_youtubers_2024[total_subscribers])
VAR sumOfTotalVideos = SUM(view_uk_youtubers_2024[total_videos])
VAR subscriberEngRate = DIVIDE(sumOfTotalSubscribers, sumOfTotalVideos, BLANK())
RETURN subscriberEngRate
Views Per Subscriber =
VAR sumOfTotalViews = SUM(view_uk_youtubers_2024[total_views])
VAR sumOfTotalSubscribers = SUM(view_uk_youtubers_2024[total_subscribers])
VAR viewsPerSubscriber = DIVIDE(sumOfTotalViews, sumOfTotalSubscribers, BLANK())
RETURN viewsPerSubscriber
For this analysis, we’re going to focus on the questions below to get the information we need for our marketing client -
Here are the key questions we need to answer for our marketing client:
Rank | Channel Name | Subscribers (M) |
---|---|---|
1 | NoCopyrightSounds | 33.60 |
2 | DanTDM | 28.60 |
3 | Dan Rhodes | 26.50 |
4 | Miss Katy | 24.50 |
5 | Mister Max | 24.40 |
6 | KSI | 24.10 |
7 | Jelly | 23.50 |
8 | Dua Lipa | 23.30 |
9 | Sidemen | 21.00 |
10 | Ali-A | 18.90 |
Rank | Channel Name | Videos Uploaded |
---|---|---|
1 | GRM Daily | 14,696 |
2 | Manchester City | 8,248 |
3 | Yogscast | 6,435 |
Rank | Channel Name | Total Views (B) |
---|---|---|
1 | DanTDM | 19.78 |
2 | Dan Rhodes | 18.56 |
3 | Mister Max | 15.97 |
Channel Name | Averge Views per Video (M) |
---|---|
Mark Ronson | 32.27 |
Jessie J | 5.97 |
Dua Lipa | 5.76 |
Rank | Channel Name | Views per Subscriber |
---|---|---|
1 | GRM Daily | 1185.79 |
2 | Nickelodeon | 1061.04 |
3 | Disney Junior UK | 1031.97 |
Rank | Channel Name | Subscriber Engagement Rate |
---|---|---|
1 | Mark Ronson | 343,000 |
2 | Jessie J | 110,416.67 |
3 | Dua Lipa | 104,954.95 |
For this analysis, we’ll prioritize analysing the metrics that are important in generating the expected ROI for our marketing client, which are the YouTube channels wuth the most
Campaign idea = product placement
b. DanTDM
c. Dan Rhodes
Best option from category: Dan Rhodes
/*
# 1. Define variables
# 2. Create a CTE that rounds the average views per video
# 3. Select the column you need and create calculated columns from existing ones
# 4. Filter results by Youtube channels
# 5. Sort results by net profits (from highest to lowest)
*/
-- 1.
DECLARE @conversionRate FLOAT = 0.02; -- The conversion rate @ 2%
DECLARE @productCost FLOAT = 5.0; -- The product cost @ $5
DECLARE @campaignCost FLOAT = 50000.0; -- The campaign cost @ $50,000
-- 2.
WITH ChannelData AS (
SELECT
channel_name,
total_views,
total_videos,
ROUND((CAST(total_views AS FLOAT) / total_videos), -4) AS rounded_avg_views_per_video
FROM
youtube_db.dbo.view_uk_youtubers_2024
)
-- 3.
SELECT
channel_name,
rounded_avg_views_per_video,
(rounded_avg_views_per_video * @conversionRate) AS potential_units_sold_per_video,
(rounded_avg_views_per_video * @conversionRate * @productCost) AS potential_revenue_per_video,
((rounded_avg_views_per_video * @conversionRate * @productCost) - @campaignCost) AS net_profit
FROM
ChannelData
-- 4.
WHERE
channel_name in ('NoCopyrightSounds', 'DanTDM', 'Dan Rhodes')
-- 5.
ORDER BY
net_profit DESC
Campaign idea = sponsored video series
b. Manchester City
b. Yogscast
Best option from category: Yogscast
/*
# 1. Define variables
# 2. Create a CTE that rounds the average views per video
# 3. Select the columns you need and create calculated columns from existing ones
# 4. Filter results by YouTube channels
# 5. Sort results by net profits (from highest to lowest)
*/
-- 1.
DECLARE @conversionRate FLOAT = 0.02; -- The conversion rate @ 2%
DECLARE @productCost FLOAT = 5.0; -- The product cost @ $5
DECLARE @campaignCostPerVideo FLOAT = 5000.0; -- The campaign cost per video @ $5,000
DECLARE @numberOfVideos INT = 11; -- The number of videos (11)
-- 2.
WITH ChannelData AS (
SELECT
channel_name,
total_views,
total_videos,
ROUND((CAST(total_views AS FLOAT) / total_videos), -4) AS rounded_avg_views_per_video
FROM
youtube_db.dbo.view_uk_youtubers_2024
)
-- 3.
SELECT
channel_name,
rounded_avg_views_per_video,
(rounded_avg_views_per_video * @conversionRate) AS potential_units_sold_per_video,
(rounded_avg_views_per_video * @conversionRate * @productCost) AS potential_revenue_per_video,
((rounded_avg_views_per_video * @conversionRate * @productCost) - (@campaignCostPerVideo * @numberOfVideos)) AS net_profit
FROM
ChannelData
-- 4.
WHERE
channel_name IN ('GRM Daily', 'Man City', 'YOGSCAST Lewis & Simon ')
-- 5.
ORDER BY
net_profit DESC;
Campaign idea = Influencer marketing
a. DanTDM
b. Dan Rhodes
c. Mister Max
Best option from category: Mister Max
/*
# 1. Define variables
# 2. Create a CTE that rounds the average views per video
# 3. Select the columns you need and create calculated columns from existing ones
# 4. Filter results by YouTube channels
# 5. Sort results by net profits (from highest to lowest)
*/
-- 1.
DECLARE @conversionRate FLOAT = 0.02; -- The conversion rate @ 2%
DECLARE @productCost MONEY = 5.0; -- The product cost @ $5
DECLARE @campaignCost MONEY = 130000.0; -- The campaign cost @ $130,000
-- 2.
WITH ChannelData AS (
SELECT
channel_name,
total_views,
total_videos,
ROUND(CAST(total_views AS FLOAT) / total_videos, -4) AS avg_views_per_video
FROM
youtube_db.dbo.view_uk_youtubers_2024
)
-- 3.
SELECT
channel_name,
avg_views_per_video,
(avg_views_per_video * @conversionRate) AS potential_units_sold_per_video,
(avg_views_per_video * @conversionRate * @productCost) AS potential_revenue_per_video,
(avg_views_per_video * @conversionRate * @productCost) - @campaignCost AS net_profit
FROM
ChannelData
-- 4.
WHERE
channel_name IN ('Mister Max', 'DanTDM', 'Dan Rhodes')
-- 5.
ORDER BY
net_profit DESC;
We discovered that
Based on our analysis, we beieve the best channel to advance a long-term partnership deal with to promote the client’s products is the Dan Rhodes channel.
We’ll have conversations with the marketing client to forecast what they also expect from this collaboration. Once we observe we’re hitting the expected milestones, we’ll advance with potential partnerships with DanTDM, Mister Max and NoCopyrightSounds channels in the future.