Skip to content
Open
Original file line number Diff line number Diff line change
Expand Up @@ -5,7 +5,9 @@ SELECT
-- https://developer.apple.com/help/app-store-connect/view-sales-and-trends/download-and-view-reports
-- "Time zone: Reports are based on Pacific Time (PT). A day includes transactions that happened from 12:00 a.m. to 11:59 p.m. PT."
-- Date conversion in the query is required to unify the dates to UTC timezone which is what we use.
* REPLACE (TIMESTAMP(DATETIME(`date`, "America/Los_Angeles")) AS `date`),
`date` AS date_pst,
-- However, the `date` timestamp field appear to always show midnight meaning if we do timezone conversion
-- we will end up moving all results 1 day back if we attempt conversion to UTC.
-- This is why we are not doing timezone converstions here.
*,
FROM
`moz-fx-data-shared-prod.app_store_syndicate.app_store_territory_source_type_report`
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
type: BIGCONFIG_FILE
tag_deployments:
- collection:
name: Operational Checks
notification_channels:
- slack: '#de-bigeye-triage'

deployments:
- column_selectors:
- name: moz-fx-data-shared-prod.moz-fx-data-shared-prod.firefox_ios_derived.app_store_funnel_v1.session_date
- name: moz-fx-data-shared-prod.moz-fx-data-shared-prod.firefox_ios_derived.app_store_funnel_v1.first_seen_date
- name: moz-fx-data-shared-prod.moz-fx-data-shared-prod.firefox_ios_derived.app_store_funnel_v1.country
metrics:
- saved_metric_id: is_not_null
rct_overrides:
- date
- column_selectors:
- name: moz-fx-data-shared-prod.moz-fx-data-shared-prod.firefox_ios_derived.app_store_funnel_v1.submission_date
- name: moz-fx-data-shared-prod.moz-fx-data-shared-prod.firefox_ios_derived.app_store_funnel_v1.country
metrics:
- saved_metric_id: composite_key_uniqueness_2_column
rct_overrides:
- date
parameters:
- key: col_1
column_name: submission_date
- key: col_1_string
string_value: submission_date
- key: col_2
column_name: country
- key: col_2_string
string_value: country
- key: table
string_value: moz-fx-data-shared-prod.firefox_ios_derived.app_store_funnel_v1
- column_selectors:
- name: moz-fx-data-shared-prod.moz-fx-data-shared-prod.firefox_ios_derived.app_store_funnel_v1.*
metrics:
- saved_metric_id: volume
- saved_metric_id: freshness

This file was deleted.

Original file line number Diff line number Diff line change
Expand Up @@ -18,6 +18,5 @@ bigquery:
type: day
field: submission_date
require_partition_filter: false
clustering:
fields:
- country
monitoring:
enabled: true
Original file line number Diff line number Diff line change
@@ -1,75 +1,141 @@
-- TODO: should we run this job with 7 day delay to make sure all data landed (a wider window to be on the safe side).
WITH views_data AS (
-- https://developer.apple.com/help/app-store-connect/view-sales-and-trends/download-and-view-reports
-- "Time zone: Reports are based on Pacific Time (PT). A day includes transactions that happened from 12:00 a.m. to 11:59 p.m. PT.
-- However, the `date` timestamp field appear to always show midnight meaning if we do timezone conversion
-- we will end up moving all results 1 day back if we attempt conversion to UTC.
-- This is why we are not doing timezone converstions here.
WITH historical_store_data AS (

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

hey, I'm not sure why the historical data subquery is required here... because the split logic for how we define things (pull downloads and impressions separately from separate tables under old format, and from one table from new format) should be encoded in the firefox_app_store_territory_source_type_report view above, no?

It's a bit confusing seeing that logic twice, maybe better to just keep that logic in one place?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

we require the historical in case we want to run the query for past data prior to 2024-01-01. historical_store_data basically should contain the old logic which required us to combine two different data sources to get impression and downloads information. The new connector based dataset already has all of this data in a single dataset so we do not need to do any additional joins.

WITH impression_data AS (
SELECT
DATE(`date`) AS `date`,
territory AS country_name,
-- Apple used to count pageviews from these sources as impressions as well but no longer do in the new data they're sending back
-- for compatibility with the new report we only want to count impressions from specific source types?
SUM(
CASE
WHEN source_type IN ('App Referrer', 'Unavailable', 'Web Referrer')
THEN 0
ELSE impressions_unique_device
END
) AS impressions,
FROM
`moz-fx-data-shared-prod.app_store.firefox_app_store_territory_source_type_report`
WHERE
DATE(`date`) = DATE_SUB(@submission_date, INTERVAL 7 DAY)
AND source_type <> 'Institutional Purchase'
AND app_id = 989804926 -- Filter to only include the Firefox app

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I thikn we only filter for institutional purchase in the downloads section in the old query... I'm totally okay with changing it (might prefer it in fact), but I'd like to check if it affects the numbers at all (I'll need access to moz-fx-data-shared-prod.app_store.firefox_downloads_territory_source_type_report to check though).

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Ditto for the app_id filter (I'm assuming it won't affect numbers and is good defensive coding, but want to validate directly)

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I could create a temp table for you which include app_id dimension

GROUP BY
`date`,
country_name
),
downloads_data AS (
SELECT
DATE(`date`) AS `date`,
territory AS country_name,
SUM(total_downloads) AS total_downloads,
SUM(first_time_downloads) AS first_time_downloads,
SUM(redownloads) AS redownloads,
FROM
`moz-fx-data-shared-prod.app_store.firefox_downloads_territory_source_type_report`
WHERE
DATE(`date`) = DATE_SUB(@submission_date, INTERVAL 7 DAY)
AND source_type <> 'Institutional Purchase'
AND app_id = 989804926 -- Filter to only include the Firefox app
GROUP BY
ALL
)
SELECT
DATE(`date`) AS `date`,
territory AS country_name,
SUM(impressions_unique_device) AS views,
country_name,
COALESCE(impressions, 0) AS impressions,
COALESCE(total_downloads, 0) AS total_downloads,
COALESCE(first_time_downloads, 0) AS first_time_downloads,
COALESCE(redownloads, 0) AS redownloads,
FROM
`moz-fx-data-shared-prod.app_store.firefox_app_store_territory_source_type_report`
WHERE
DATE(`date`) = DATE_SUB(@submission_date, INTERVAL 7 DAY)
GROUP BY
`date`,
country_name
impression_data
FULL OUTER JOIN
downloads_data
USING (`date`, country_name)
),
downloads_data AS (
app_store_data AS (
SELECT
DATE(`date`) AS `date`,
territory AS country_name,
date_day AS `date`,
territory_long AS country_name,
SUM(impressions_unique_device) AS impressions,
SUM(total_downloads) AS total_downloads,
SUM(first_time_downloads) AS first_time_downloads,
SUM(redownloads) AS redownloads,
FROM
`moz-fx-data-shared-prod.app_store.firefox_downloads_territory_source_type_report`
`moz-fx-data-bq-fivetran.firefox_app_store_v2_apple_store.apple_store__territory_report`
WHERE
DATE(`date`) = DATE_SUB(@submission_date, INTERVAL 7 DAY)
DATE(date_day) = DATE_SUB(@submission_date, INTERVAL 7 DAY)
AND source_type <> 'Institutional Purchase'
AND app_id = 989804926 -- Filter to only include the Firefox app
GROUP BY
ALL
),
combine_app_store_data AS (
SELECT
`date`,
country_name
country_name,
impressions,
total_downloads,
first_time_downloads,
redownloads,
FROM
historical_store_data
WHERE
`date` < "2024-01-01"
UNION ALL
SELECT
`date`,
country_name,
impressions,
total_downloads,
first_time_downloads,
redownloads,
FROM
app_store_data
WHERE
`date` >= "2024-01-01"
),
store_stats AS (
normalize_country AS (
SELECT
DATE(`date`) AS `date`,
`date`,
country_names.code AS country,
views,
impressions,
total_downloads,
first_time_downloads,
redownloads,
FROM
views_data
FULL OUTER JOIN
downloads_data
USING (`date`, country_name)
combine_app_store_data
LEFT JOIN
`moz-fx-data-shared-prod.static.country_names_v1` AS country_names
ON country_names.name = views_data.country_name
ON combine_app_store_data.country_name = country_names.name
),
_new_profiles AS (
SELECT
first_seen_date AS `date`,
first_reported_country AS country,
COUNT(*) AS new_profiles,
country,
SUM(new_profiles) AS new_profiles,
FROM
`moz-fx-data-shared-prod.firefox_ios.firefox_ios_clients`
`moz-fx-data-shared-prod.firefox_ios.new_profiles`
WHERE
first_seen_date = DATE_SUB(@submission_date, INTERVAL 7 DAY)
AND channel = "release"
AND normalized_channel = "release"
GROUP BY
`date`,
country
ALL
)
SELECT
@submission_date AS submission_date,
`date` AS first_seen_date,
country,
COALESCE(views, 0) AS impressions,
COALESCE(total_downloads, 0) AS total_downloads,
COALESCE(first_time_downloads, 0) AS first_time_downloads,
COALESCE(redownloads, 0) AS redownloads,
impressions,
total_downloads,
first_time_downloads,
redownloads,
COALESCE(new_profiles, 0) AS new_profiles,
FROM
store_stats
FULL OUTER JOIN
normalize_country
LEFT JOIN
_new_profiles
USING (`date`, country)