Skip to content
Merged
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
friendly_name: Fxa Win10 Users Daily
description: |-
This query identifies Firefox Accounts users on Windows 10 who have been inactive for exactly 14 days and
prepares their records for Braze by assigning an external ID and email.
owners:
- [email protected]
labels:
incremental: false
schedule: daily
owner: lmcfall
scheduling:
dag_name: bqetl_braze
Original file line number Diff line number Diff line change
@@ -0,0 +1,77 @@
WITH win10_users AS (
SELECT DISTINCT
TO_HEX(SHA256(metrics.string.client_association_uid)) AS fxa_id_sha256,
FIRST_VALUE(DATE(submission_timestamp)) OVER (
PARTITION BY
TO_HEX(SHA256(metrics.string.client_association_uid))
ORDER BY
submission_timestamp DESC
) AS submission_date,
FIRST_VALUE(client_info.os) OVER (
PARTITION BY
TO_HEX(SHA256(metrics.string.client_association_uid))
ORDER BY
submission_timestamp DESC
) AS os,
FIRST_VALUE(client_info.os_version) OVER (
PARTITION BY
TO_HEX(SHA256(metrics.string.client_association_uid))
ORDER BY
submission_timestamp DESC
) AS os_version,
FIRST_VALUE(client_info.locale) OVER (
PARTITION BY
TO_HEX(SHA256(metrics.string.client_association_uid))
ORDER BY
submission_timestamp DESC
) AS locale
FROM
`moz-fx-data-shared-prod.firefox_desktop.fx_accounts`
WHERE
DATE(submission_timestamp) = @submission_date
AND client_info.os = 'Windows'
AND client_info.os_version = '10.0'
),
last_seen_14_days AS (
SELECT DISTINCT
user_id_sha256
FROM
`moz-fx-data-shared-prod.accounts_backend_derived.users_services_last_seen_v1`
WHERE
submission_date = @submission_date
-- bit pattern 100000000000000, last seen 14 days from submission date
AND days_seen_bits = 16384
),
inactive_win10_users AS (
SELECT
win10.submission_date,
last_seen.user_id_sha256,
win10.os,
win10.os_version,
win10.locale
FROM
last_seen_14_days AS last_seen
LEFT JOIN
win10_users AS win10
ON last_seen.user_id_sha256 = win10.fxa_id_sha256
-- filter out users that don't have an FX account
WHERE
win10.fxa_id_sha256 IS NOT NULL
)
SELECT
inactive.submission_date,
braze_users.external_id AS external_id,
-- if user is in our braze users table use their email, otherwise use the email associated with their fxa_id
IFNULL(braze_users.email, fxa_emails.normalizedEmail) AS email,
inactive.user_id_sha256,
inactive.locale
FROM
inactive_win10_users AS inactive
LEFT JOIN
`moz-fx-data-shared-prod.braze_derived.users_v1` AS braze_users
ON inactive.user_id_sha256 = braze_users.fxa_id_sha256
LEFT JOIN
`moz-fx-data-shared-prod.accounts_backend_external.emails_v1` AS fxa_emails
ON inactive.user_id_sha256 = TO_HEX(SHA256(fxa_emails.uid))
-- some users have multiple email addresses in this table, only use primary
AND fxa_emails.isPrimary = TRUE
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
friendly_name: Fxa Win10 Users Historical
description: |-
This query compiles the full list of Win10 users who have reached 14 days of inactivity.

owners:
- [email protected]
labels:
incremental: true
schedule: daily
owner: lmcfall
scheduling:
dag_name: bqetl_braze
bigquery:
time_partitioning:
type: day
field: submission_date
require_partition_filter: false
expiration_days: null
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
WITH current_list AS (
SELECT
fxa_id_sha256
FROM
`moz-fx-data-shared-prod.braze_derived.fxa_win10_users_historical_v1`
)
SELECT
daily.submission_date,
IFNULL(daily.external_id, TO_HEX(SHA256(GENERATE_UUID()))) AS external_id,
daily.email,
daily.locale,
daily.user_id_sha256 AS fxa_id_sha256
FROM
`moz-fx-data-shared-prod.braze_derived.fxa_win10_users_daily_v1` AS daily
LEFT JOIN
current_list AS historical
ON historical.fxa_id_sha256 = daily.user_id_sha256
WHERE
submission_date = @submission_date
AND daily.email IS NOT NULL
-- FILTER OUT USERS ALREADY IN THE LIST
AND historical.fxa_id_sha256 IS NULL
-- ONLY FOR EMAIL WARMING IN en-US LOCALE
-- REMOVE THIS FILTER BEFORE 10/14/2025 WHEN FULL CAMPAIGN STARTS
AND daily.locale = 'en-US'
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
friendly_name: Win10 Users Sync
description: |-
This table will sync inactive Windows 10 Firefox users to Braze to be contacted
in the Win10 Inactive User Campaign.
owners:
- [email protected]
labels:
incremental: true
owner1: lmcfall
scheduling:
dag_name: bqetl_braze
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
SELECT
CURRENT_TIMESTAMP() AS updated_at,
external_id,
TO_JSON(
STRUCT(
email AS email,
"subscribed" AS email_subscribe,
STRUCT(
"718eea53-371c-4cc6-9fdc-1260b1311bd8" AS subscription_group_id,
"subscribed" AS subscription_state
) AS subscription_groups,
locale AS locale,
fxa_id_sha256
)
) AS payload
FROM
`moz-fx-data-shared-prod.braze_derived.fxa_win10_users_historical_v1`
WHERE
submission_date = @submission_date