Skip to content

Commit

Permalink
[RS-834] Add country to search_revenue_levers_daily (#4739)
Browse files Browse the repository at this point in the history
* Add country

* change channel spellings so match revenue table

* update country list

* Reformat

* Update desktop DAU definition

Can't update mobile DAU by engine breakouts w/o changes to mobile_search_clients_daily. But we also don't need that option since default engine is currently buggy and searchers presumably have > 0 active seconds

* Fix sql format

---------

Co-authored-by: Alekhya <88394696+alekhyamoz@users.noreply.github.com>
Co-authored-by: Alekhya Kommasani <akommasani@mozilla.com>
  • Loading branch information
3 people committed May 28, 2024
1 parent 4cc2aad commit 772309a
Showing 1 changed file with 68 additions and 33 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -3,17 +3,25 @@ WITH
desktop_data_google AS (
SELECT
submission_date,
IF(LOWER(channel) LIKE '%esr%', 'esr', 'personal') AS channel,
IF(country = 'US', 'US', 'RoW') AS country,
COUNT(DISTINCT client_id) AS dau,
IF(LOWER(channel) LIKE '%esr%', 'ESR', 'personal') AS channel,
country,
COUNT(DISTINCT IF(active_hours_sum > 0 AND total_uri_count > 0, client_id, NULL)) AS dau,
COUNT(
DISTINCT IF(default_search_engine LIKE '%google%', client_id, NULL)
DISTINCT IF(
default_search_engine LIKE '%google%'
AND active_hours_sum > 0
AND total_uri_count > 0,
client_id,
NULL
)
) AS dau_w_engine_as_default,
COUNT(
DISTINCT IF(
sap > 0
AND normalized_engine = 'Google'
AND default_search_engine LIKE '%google%',
AND default_search_engine LIKE '%google%'
AND active_hours_sum > 0
AND total_uri_count > 0,
client_id,
NULL
)
Expand All @@ -31,7 +39,10 @@ desktop_data_google AS (
`moz-fx-data-shared-prod.search.search_clients_engines_sources_daily`
WHERE
submission_date = @submission_date
AND country NOT IN ('RU', 'UA', 'TR', 'BY', 'KZ', 'CN')
AND (
(submission_date < "2023-12-01" AND country NOT IN ('RU', 'UA', 'TR', 'BY', 'KZ', 'CN'))
OR (submission_date >= "2023-12-01" AND country NOT IN ('RU', 'UA', 'BY', 'CN'))
)
GROUP BY
submission_date,
channel,
Expand All @@ -45,16 +56,24 @@ desktop_data_google AS (
desktop_data_bing AS (
SELECT
submission_date,
IF(country = 'US', 'US', 'RoW') AS country,
COUNT(DISTINCT client_id) AS dau,
country,
COUNT(DISTINCT IF(active_hours_sum > 0 AND total_uri_count > 0, client_id, NULL)) AS dau,
COUNT(
DISTINCT IF(default_search_engine LIKE '%bing%', client_id, NULL)
DISTINCT IF(
default_search_engine LIKE '%bing%'
AND active_hours_sum > 0
AND total_uri_count > 0,
client_id,
NULL
)
) AS dau_w_engine_as_default,
COUNT(
DISTINCT IF(
sap > 0
AND normalized_engine = 'Bing'
AND default_search_engine LIKE '%bing%',
AND default_search_engine LIKE '%bing%'
AND active_hours_sum > 0
AND total_uri_count > 0,
client_id,
NULL
)
Expand Down Expand Up @@ -85,14 +104,16 @@ desktop_data_bing AS (
desktop_data_ddg AS (
SELECT
submission_date,
IF(country = 'US', 'US', 'RoW') AS country,
COUNT(DISTINCT client_id) AS dau,
country,
COUNT(DISTINCT IF(active_hours_sum > 0 AND total_uri_count > 0, client_id, NULL)) AS dau,
COUNT(
DISTINCT IF(
(
(default_search_engine LIKE('%ddg%') OR default_search_engine LIKE('%duckduckgo%'))
AND NOT default_search_engine LIKE('%addon%')
),
)
AND active_hours_sum > 0
AND total_uri_count > 0,
client_id,
NULL
)
Expand All @@ -104,7 +125,9 @@ desktop_data_ddg AS (
AND (
(default_search_engine LIKE('%ddg%') OR default_search_engine LIKE('%duckduckgo%'))
AND NOT default_search_engine LIKE('%addon%')
),
)
AND active_hours_sum > 0
AND total_uri_count > 0,
client_id,
NULL
)
Expand All @@ -122,13 +145,21 @@ desktop_data_ddg AS (
SUM(IF(engine IN ('ddg', 'duckduckgo') AND is_sap_monetizable, sap, 0)) AS ddg_monetizable_sap,
-- in-content probes not available for addon so these metrics although being here will be zero
COUNT(
DISTINCT IF(default_search_engine LIKE('ddg%addon'), client_id, NULL)
DISTINCT IF(
default_search_engine LIKE('ddg%addon')
AND active_hours_sum > 0
AND total_uri_count > 0,
client_id,
NULL
)
) AS ddgaddon_dau_w_engine_as_default,
COUNT(
DISTINCT IF(
engine = 'ddg-addon'
AND sap > 0
AND default_search_engine LIKE('ddg%addon'),
AND default_search_engine LIKE('ddg%addon')
AND active_hours_sum > 0
AND total_uri_count > 0,
client_id,
NULL
)
Expand Down Expand Up @@ -159,28 +190,29 @@ desktop_data_ddg AS (
mobile_dau_data AS (
SELECT
submission_date,
SUM(
IF(country NOT IN ('US', 'RU', 'UA', 'BY', 'TR', 'KZ', 'CN'), dau, 0)
) AS row_dau_eligible_google,
SUM(IF(country = 'US', dau, 0)) AS us_dau,
SUM(IF(country != 'US', dau, 0)) AS row_dau,
country,
SUM(dau) AS dau
FROM
`moz-fx-data-shared-prod.telemetry.active_users_aggregates_device`
`moz-fx-data-shared-prod.telemetry.active_users_aggregates`
WHERE
submission_date = @submission_date
AND app_name IN ('Fenix', 'Firefox iOS', 'Focus Android', 'Focus iOS')
AND (
(submission_date < "2023-12-01" AND country NOT IN ('RU', 'UA', 'TR', 'BY', 'KZ', 'CN'))
OR (submission_date >= "2023-12-01" AND country NOT IN ('RU', 'UA', 'BY', 'CN'))
)
GROUP BY
submission_date
submission_date,
country
),
-- Google Mobile (search only - as mobile search metrics is based on metrics
-- ping, while DAU should be based on main ping on Mobile, see also
-- https://mozilla-hub.atlassian.net/browse/RS-575)
mobile_data_google AS (
SELECT
submission_date,
IF(country = 'US', 'US', 'RoW') AS country,
IF(country = 'US', dau.us_dau, dau.row_dau_eligible_google) AS dau,
country,
dau,
COUNT(
DISTINCT IF(default_search_engine LIKE '%google%', client_id, NULL)
) AS dau_w_engine_as_default,
Expand All @@ -206,11 +238,14 @@ mobile_data_google AS (
FROM
`moz-fx-data-shared-prod.search.mobile_search_clients_engines_sources_daily`
INNER JOIN
mobile_dau_data dau
USING (submission_date)
mobile_dau_data
USING (submission_date, country)
WHERE
submission_date = @submission_date
AND country NOT IN ('RU', 'UA', 'BY', 'TR', 'KZ', 'CN')
AND (
(submission_date < "2023-12-01" AND country NOT IN ('RU', 'UA', 'TR', 'BY', 'KZ', 'CN'))
OR (submission_date >= "2023-12-01" AND country NOT IN ('RU', 'UA', 'BY', 'CN'))
)
AND (
app_name IN ('Fenix', 'Firefox Preview', 'Focus', 'Focus Android Glean', 'Focus iOS Glean')
OR (app_name = 'Fennec' AND os = 'iOS')
Expand All @@ -230,8 +265,8 @@ mobile_data_google AS (
mobile_data_bing_ddg AS (
SELECT
submission_date,
IF(country = 'US', 'US', 'RoW') AS country,
IF(country = 'US', dau.us_dau, dau.row_dau) AS dau,
country,
dau,
COUNT(
DISTINCT IF(default_search_engine LIKE '%bing%', client_id, NULL)
) AS bing_dau_w_engine_as_default,
Expand Down Expand Up @@ -284,8 +319,8 @@ mobile_data_bing_ddg AS (
FROM
`moz-fx-data-shared-prod.search.mobile_search_clients_engines_sources_daily`
INNER JOIN
mobile_dau_data dau
USING (submission_date)
mobile_dau_data
USING (submission_date, country)
WHERE
submission_date = @submission_date
AND (
Expand Down Expand Up @@ -390,7 +425,7 @@ SELECT
submission_date,
'Google' AS partner,
'mobile' AS device,
NULL AS channel,
'n/a' AS channel,
country,
dau,
dau_engaged_w_sap,
Expand Down

0 comments on commit 772309a

Please sign in to comment.