DENG-3615 QA Fixes for Braze models (#5508)
* changing structure of payload and structuring timestamps * updating time filter and standardizing * adding changed subscriptions model and updating time filter * moving udf to separate pr and changing source table * adding comments and moving max to timestamps * filtering out mofo users and fxa_account_deleted true" * updating filter on tables to pull most recent and adding acoustic event data * formatting and refactoring * formatting * updating format and adding comments * removing time filter * fix alias * reverting waitlists code back to original * add lower() to waitlists platform and source * ading inner join to users * fix test_braze_subscriptions * fix test_braze_waitlists --------- Co-authored-by: Leli Schiestl <lschiestl@mozilla.com>
This commit is contained in:
Родитель
1e307e423f
Коммит
3df6f02cdb
|
@ -1,8 +1,8 @@
|
|||
WITH unified AS (
|
||||
WITH unified_data AS (
|
||||
-- Combine newsletters and waitlists into a single set of records from user_profiles
|
||||
SELECT
|
||||
external_id,
|
||||
newsletter.newsletter_name AS subscription_name, -- No change to name for newsletters
|
||||
newsletter.newsletter_name AS subscription_name,
|
||||
newsletter.update_timestamp,
|
||||
IF(newsletter.subscribed, 'subscribed', 'unsubscribed') AS subscription_state
|
||||
FROM
|
||||
|
@ -11,44 +11,43 @@ WITH unified AS (
|
|||
UNION ALL
|
||||
SELECT
|
||||
external_id,
|
||||
CONCAT(
|
||||
waitlist.waitlist_name,
|
||||
'-waitlist'
|
||||
) AS subscription_name, -- Add '-waitlist' suffix to match braze naming
|
||||
CASE
|
||||
WHEN waitlist.waitlist_name = 'vpn'
|
||||
THEN 'guardian-vpn-waitlist'
|
||||
ELSE CONCAT(waitlist.waitlist_name, '-waitlist')
|
||||
END AS subscription_name,
|
||||
waitlist.update_timestamp,
|
||||
IF(waitlist.subscribed, 'subscribed', 'unsubscribed') AS subscription_state
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_derived.user_profiles_v1`,
|
||||
UNNEST(waitlists) AS waitlist
|
||||
),
|
||||
all_subscriptions AS (
|
||||
-- Create a comprehensive list of all users and their potential subscriptions
|
||||
subscriptions AS (
|
||||
SELECT
|
||||
users.external_id,
|
||||
map.braze_subscription_name AS subscription_name,
|
||||
map.firefox_subscription_id,
|
||||
map.mozilla_subscription_id,
|
||||
map.mozilla_dev_subscription_id
|
||||
external_id,
|
||||
subscription_name,
|
||||
MAX(update_timestamp) AS update_timestamp,
|
||||
MAX(subscription_state) AS subscription_state
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_derived.users_v1` AS users
|
||||
CROSS JOIN
|
||||
`moz-fx-data-shared-prod.braze_derived.subscriptions_map_v1` AS map
|
||||
unified_data
|
||||
GROUP BY
|
||||
external_id,
|
||||
subscription_name
|
||||
),
|
||||
subscriptions_mapped AS (
|
||||
SELECT
|
||||
all_subscriptions.external_id,
|
||||
all_subscriptions.subscription_name,
|
||||
all_subscriptions.firefox_subscription_id,
|
||||
all_subscriptions.mozilla_subscription_id,
|
||||
all_subscriptions.mozilla_dev_subscription_id,
|
||||
COALESCE(unified.subscription_state, 'unsubscribed') AS subscription_state,
|
||||
unified.update_timestamp
|
||||
subscriptions.external_id,
|
||||
subscriptions.subscription_name,
|
||||
map.firefox_subscription_id,
|
||||
map.mozilla_subscription_id,
|
||||
map.mozilla_dev_subscription_id,
|
||||
subscriptions.subscription_state,
|
||||
subscriptions.update_timestamp
|
||||
FROM
|
||||
all_subscriptions
|
||||
LEFT JOIN
|
||||
unified
|
||||
ON unified.external_id = all_subscriptions.external_id
|
||||
AND unified.subscription_name = all_subscriptions.subscription_name
|
||||
subscriptions
|
||||
JOIN
|
||||
`moz-fx-data-shared-prod.braze_derived.subscriptions_map_v1` AS map
|
||||
ON subscriptions.subscription_name = map.braze_subscription_name
|
||||
)
|
||||
SELECT
|
||||
subscriptions_mapped.external_id AS external_id,
|
||||
|
@ -67,4 +66,8 @@ SELECT
|
|||
FROM
|
||||
subscriptions_mapped
|
||||
GROUP BY
|
||||
subscriptions_mapped.external_id;
|
||||
subscriptions_mapped.external_id
|
||||
HAVING
|
||||
COUNT(
|
||||
subscriptions_mapped.subscription_name
|
||||
) > 0; -- Only include rows where subscription IDs are not null
|
||||
|
|
|
@ -2,8 +2,10 @@ WITH ctms_emails AS (
|
|||
SELECT
|
||||
emails.email_id AS external_id,
|
||||
LOWER(emails.primary_email) AS email,
|
||||
LOWER(emails.mailing_country) AS mailing_country,
|
||||
NULLIF(LOWER(emails.mailing_country), '') AS mailing_country,
|
||||
CASE
|
||||
WHEN emails.has_opted_out_of_email = TRUE
|
||||
THEN "unsubscribed"
|
||||
WHEN emails.double_opt_in = TRUE
|
||||
THEN 'opted_in'
|
||||
WHEN emails.double_opt_in = FALSE
|
||||
|
@ -12,7 +14,7 @@ WITH ctms_emails AS (
|
|||
ELSE 'unsubscribed'
|
||||
END AS email_subscribe,
|
||||
emails.basket_token,
|
||||
LOWER(emails.email_lang) AS email_lang,
|
||||
NULLIF(LOWER(emails.email_lang), '') AS email_lang,
|
||||
TO_HEX(SHA256(fxa.fxa_id)) AS fxa_id_sha256,
|
||||
CASE
|
||||
WHEN fxa.fxa_id IS NOT NULL
|
||||
|
@ -20,54 +22,116 @@ WITH ctms_emails AS (
|
|||
THEN TRUE
|
||||
END AS has_fxa,
|
||||
LOWER(fxa.primary_email) AS fxa_primary_email,
|
||||
LOWER(fxa.lang) AS fxa_lang,
|
||||
LOWER(fxa.first_service) AS fxa_first_service,
|
||||
NULLIF(LOWER(fxa.lang), '') AS fxa_lang,
|
||||
NULLIF(LOWER(fxa.first_service), '') AS fxa_first_service,
|
||||
has_opted_out_of_email,
|
||||
CAST(fxa.created_date AS TIMESTAMP) AS fxa_created_at,
|
||||
emails.create_timestamp,
|
||||
emails.update_timestamp
|
||||
emails.create_timestamp AS create_timestamp,
|
||||
emails.update_timestamp AS update_timestamp
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_emails` AS emails
|
||||
LEFT JOIN
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_fxa` AS fxa
|
||||
ON emails.email_id = fxa.email_id
|
||||
),
|
||||
active_users AS (
|
||||
-- latest engagement date from Acoustic events, filtered by event type
|
||||
acoustic_events AS (
|
||||
SELECT
|
||||
emails.external_id,
|
||||
emails.email,
|
||||
emails.email_subscribe,
|
||||
emails.mailing_country,
|
||||
emails.basket_token,
|
||||
emails.email_lang,
|
||||
emails.fxa_id_sha256,
|
||||
emails.has_fxa,
|
||||
emails.fxa_primary_email,
|
||||
emails.fxa_lang,
|
||||
emails.fxa_first_service,
|
||||
emails.fxa_created_at,
|
||||
emails.create_timestamp,
|
||||
emails.update_timestamp
|
||||
contacts.email_id,
|
||||
MAX(
|
||||
PARSE_TIMESTAMP("%m/%d/%Y %H:%M:%S", recipients.event_timestamp)
|
||||
) AS acoustic_last_engaged_at
|
||||
FROM
|
||||
ctms_emails AS emails
|
||||
LEFT JOIN
|
||||
`moz-fx-data-shared-prod.braze_derived.suppressions_v1` AS suppressions
|
||||
ON emails.email = suppressions.email
|
||||
LEFT JOIN
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_fxa` AS fxa
|
||||
ON emails.external_id = fxa.email_id
|
||||
`moz-fx-data-shared-prod.acoustic_external.raw_recipient_raw_v1` AS recipients
|
||||
JOIN
|
||||
`moz-fx-data-shared-prod.acoustic_external.contact_raw_v1` AS contacts
|
||||
ON recipients.recipient_id = contacts.recipient_id
|
||||
WHERE
|
||||
-- exclude users on suppression list
|
||||
suppressions.email IS NULL
|
||||
-- ensure user is associated w/ active subscription or product
|
||||
AND (
|
||||
EXISTS(
|
||||
recipients.event_type IN ('Open', 'Click Through') -- Filtering events by type
|
||||
GROUP BY
|
||||
contacts.email_id
|
||||
)
|
||||
SELECT
|
||||
emails.external_id AS external_id,
|
||||
emails.email AS email,
|
||||
emails.email_subscribe AS email_subscribe,
|
||||
emails.mailing_country AS mailing_country,
|
||||
emails.basket_token AS basket_token,
|
||||
emails.email_lang AS email_lang,
|
||||
emails.fxa_id_sha256 AS fxa_id_sha256,
|
||||
emails.has_fxa AS has_fxa,
|
||||
emails.fxa_primary_email AS fxa_primary_email,
|
||||
emails.fxa_lang AS fxa_lang,
|
||||
emails.fxa_first_service AS fxa_first_service,
|
||||
emails.fxa_created_at AS fxa_created_at,
|
||||
emails.create_timestamp AS create_timestamp,
|
||||
emails.update_timestamp AS update_timestamp,
|
||||
events.acoustic_last_engaged_at AS acoustic_last_engaged_at
|
||||
FROM
|
||||
ctms_emails AS emails
|
||||
LEFT JOIN
|
||||
acoustic_events AS events
|
||||
ON emails.external_id = events.email_id
|
||||
LEFT JOIN
|
||||
`moz-fx-data-shared-prod.marketing_suppression_list_derived.main_suppression_list_v1` AS suppressions
|
||||
ON emails.email = suppressions.email
|
||||
LEFT JOIN
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_fxa` AS fxa
|
||||
ON emails.external_id = fxa.email_id
|
||||
WHERE
|
||||
suppressions.email IS NULL -- exclude users on suppression list
|
||||
AND emails.has_opted_out_of_email = FALSE -- has not opted out of all newsletters
|
||||
AND fxa.account_deleted = FALSE -- has not deleted FxA
|
||||
AND (
|
||||
EXISTS(
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_newsletters` AS newsletters
|
||||
WHERE
|
||||
newsletters.email_id = emails.external_id
|
||||
AND newsletters.subscribed = TRUE
|
||||
)
|
||||
OR EXISTS(
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_waitlists` AS waitlists
|
||||
WHERE
|
||||
waitlists.email_id = emails.external_id
|
||||
AND waitlists.subscribed = TRUE
|
||||
)
|
||||
OR EXISTS(
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.subscription_platform.logical_subscriptions` AS products
|
||||
WHERE
|
||||
products.mozilla_account_id_sha256 = emails.fxa_id_sha256
|
||||
)
|
||||
)
|
||||
AND (
|
||||
-- Check if user is not subscribed only to 'mozilla-foundation' and has at least one other subscription
|
||||
(
|
||||
NOT EXISTS(
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_newsletters` AS newsletters
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_newsletters` AS mofo_newsletters
|
||||
WHERE
|
||||
newsletters.email_id = emails.external_id
|
||||
AND newsletters.subscribed = TRUE
|
||||
mofo_newsletters.email_id = emails.external_id
|
||||
AND mofo_newsletters.subscribed = TRUE
|
||||
AND mofo_newsletters.name = 'mozilla-foundation'
|
||||
)
|
||||
OR EXISTS(
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_newsletters` AS other_newsletters
|
||||
WHERE
|
||||
other_newsletters.email_id = emails.external_id
|
||||
AND other_newsletters.subscribed = TRUE
|
||||
AND other_newsletters.name != 'mozilla-foundation'
|
||||
)
|
||||
OR EXISTS(
|
||||
SELECT
|
||||
|
@ -82,26 +146,9 @@ active_users AS (
|
|||
SELECT
|
||||
1
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.subscription_platform_derived.stripe_subscriptions_v1` AS products
|
||||
`moz-fx-data-shared-prod.subscription_platform.logical_subscriptions` AS subscriptions
|
||||
WHERE
|
||||
products.fxa_uid = emails.fxa_id_sha256
|
||||
subscriptions.mozilla_account_id_sha256 = emails.fxa_id_sha256
|
||||
)
|
||||
)
|
||||
)
|
||||
SELECT
|
||||
external_id,
|
||||
email,
|
||||
email_subscribe,
|
||||
mailing_country,
|
||||
basket_token,
|
||||
email_lang,
|
||||
fxa_id_sha256,
|
||||
has_fxa,
|
||||
fxa_primary_email,
|
||||
fxa_lang,
|
||||
fxa_first_service,
|
||||
fxa_created_at,
|
||||
create_timestamp,
|
||||
update_timestamp
|
||||
FROM
|
||||
active_users;
|
||||
)
|
||||
|
|
|
@ -41,3 +41,6 @@ fields:
|
|||
- mode: NULLABLE
|
||||
name: fxa_created_at
|
||||
type: TIMESTAMP
|
||||
- mode: NULLABLE
|
||||
name: acoustic_last_engaged_at
|
||||
type: TIMESTAMP
|
||||
|
|
|
@ -4,20 +4,23 @@ SELECT
|
|||
STRUCT(
|
||||
name AS waitlist_name,
|
||||
LOWER(JSON_EXTRACT_SCALAR(fields, '$.geo')) AS waitlist_geo,
|
||||
JSON_EXTRACT_SCALAR(fields, '$.platform') AS waitlist_platform,
|
||||
source AS waitlist_source,
|
||||
create_timestamp,
|
||||
subscribed,
|
||||
unsub_reason,
|
||||
update_timestamp
|
||||
LOWER(JSON_EXTRACT_SCALAR(fields, '$.platform')) AS waitlist_platform,
|
||||
LOWER(source) AS waitlist_source,
|
||||
waitlists.create_timestamp AS create_timestamp,
|
||||
waitlists.subscribed AS subscribed,
|
||||
waitlists.unsub_reason AS unsub_reason,
|
||||
waitlists.update_timestamp AS update_timestamp
|
||||
)
|
||||
ORDER BY
|
||||
update_timestamp,
|
||||
create_timestamp,
|
||||
name
|
||||
waitlists.update_timestamp,
|
||||
waitlists.create_timestamp,
|
||||
waitlists.name
|
||||
) AS waitlists
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_waitlists`
|
||||
`moz-fx-data-shared-prod.ctms_braze.ctms_waitlists` AS waitlists
|
||||
INNER JOIN
|
||||
`moz-fx-data-shared-prod.braze_derived.users_v1` AS users
|
||||
ON users.external_id = waitlists.email_id
|
||||
GROUP BY
|
||||
email_id
|
||||
HAVING
|
||||
|
|
|
@ -1,9 +1,4 @@
|
|||
WITH max_update AS (
|
||||
SELECT
|
||||
MAX(UPDATED_AT) AS max_update_timestamp
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_external.changed_firefox_subscriptions_sync_v1`
|
||||
)
|
||||
-- Construct the JSON payload in Braze required format
|
||||
SELECT
|
||||
CURRENT_TIMESTAMP() AS UPDATED_AT,
|
||||
subscriptions.external_id AS EXTERNAL_ID,
|
||||
|
@ -20,10 +15,8 @@ SELECT
|
|||
)
|
||||
) AS PAYLOAD
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_derived.subscriptions_v1` AS subscriptions
|
||||
`moz-fx-data-shared-prod.braze_external.changed_subscriptions_v1` AS subscriptions
|
||||
CROSS JOIN
|
||||
UNNEST(subscriptions.subscriptions) AS subscriptions_array
|
||||
WHERE
|
||||
subscriptions_array.update_timestamp > (SELECT max_update_timestamp FROM max_update)
|
||||
GROUP BY
|
||||
subscriptions.external_id;
|
||||
|
|
|
@ -1,9 +1,14 @@
|
|||
-- Retrieves the maximum newsletter updated timestamp from the last run to only
|
||||
-- select recently changed records
|
||||
WITH max_update AS (
|
||||
SELECT
|
||||
MAX(UPDATED_AT) AS max_update_timestamp
|
||||
MAX(
|
||||
TIMESTAMP(JSON_VALUE(payload.newsletters_v1[0].update_timestamp, '$."$time"'))
|
||||
) AS latest_newsletter_updated_at
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_external.changed_newsletters_sync_v1`
|
||||
)
|
||||
-- Construct the JSON payload in Braze required format
|
||||
SELECT
|
||||
CURRENT_TIMESTAMP() AS UPDATED_AT,
|
||||
newsletters.external_id AS EXTERNAL_ID,
|
||||
|
@ -22,14 +27,14 @@ SELECT
|
|||
newsletters_array.create_timestamp,
|
||||
'UTC'
|
||||
) AS `$time`
|
||||
) AS create_timestamp,
|
||||
) AS created_at,
|
||||
STRUCT(
|
||||
FORMAT_TIMESTAMP(
|
||||
'%Y-%m-%d %H:%M:%E6S UTC',
|
||||
newsletters_array.update_timestamp,
|
||||
'UTC'
|
||||
) AS `$time`
|
||||
) AS update_timestamp
|
||||
) AS updated_at
|
||||
)
|
||||
ORDER BY
|
||||
newsletters_array.update_timestamp DESC
|
||||
|
@ -41,6 +46,6 @@ FROM
|
|||
CROSS JOIN
|
||||
UNNEST(newsletters.newsletters) AS newsletters_array
|
||||
WHERE
|
||||
newsletters_array.update_timestamp > (SELECT max_update_timestamp FROM max_update)
|
||||
newsletters_array.update_timestamp > (SELECT latest_newsletter_updated_at FROM max_update)
|
||||
GROUP BY
|
||||
newsletters.external_id;
|
||||
|
|
|
@ -1,11 +1,14 @@
|
|||
-- Retrieves the maximum subscription updated timestamp from the last run to only
|
||||
-- select recently changed records
|
||||
WITH max_update AS (
|
||||
SELECT
|
||||
MAX(UPDATED_AT) AS max_update_timestamp
|
||||
MAX(
|
||||
TIMESTAMP(JSON_VALUE(payload.products_v1[0].subscription_updated_at, '$."$time"'))
|
||||
) AS latest_subscription_updated_at
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_external.changed_products_sync_v1`
|
||||
LIMIT
|
||||
1
|
||||
),
|
||||
-- Counts the number of subscriptions per product
|
||||
products_with_counts AS (
|
||||
SELECT
|
||||
products.external_id,
|
||||
|
@ -20,8 +23,9 @@ products_with_counts AS (
|
|||
CROSS JOIN
|
||||
UNNEST(products.products) AS products_array
|
||||
WHERE
|
||||
products_array.subscription_updated_at > (SELECT max_update_timestamp FROM max_update)
|
||||
products_array.subscription_updated_at > (SELECT latest_subscription_updated_at FROM max_update)
|
||||
)
|
||||
-- Construct the JSON payload in Braze required format
|
||||
SELECT
|
||||
CURRENT_TIMESTAMP() AS UPDATED_AT,
|
||||
products.external_id AS EXTERNAL_ID,
|
||||
|
|
|
@ -1,9 +1,8 @@
|
|||
friendly_name: Braze Changed Subscriptions Sync | Firefox Workspace
|
||||
friendly_name: Braze Changed Subscriptions
|
||||
description: |-
|
||||
Changes in subscriptions in Braze from the previous day - mapped to the Firefox workspace.
|
||||
In order to consume the least amount of data points, we only want to sync rows changed
|
||||
since the last sync. This table holds all of the changed subscription data that syncs to braze.
|
||||
|
||||
This table represents changes to user subscriptions since the
|
||||
previous DAG run. It enables us to build the changed subscriptions
|
||||
sync(s)
|
||||
|
||||
See https://mozilla-hub.atlassian.net/browse/DENG-3182
|
||||
owners:
|
||||
|
|
|
@ -1,36 +1,42 @@
|
|||
WITH max_update_timestamp AS (
|
||||
-- CTE to determine the maximum update timestamp from changed_subscriptions_v1
|
||||
WITH max_update AS (
|
||||
SELECT
|
||||
MAX(subscriptions.update_timestamp) AS latest_subscription_updated_at
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_external.changed_subscriptions_v1` AS changed,
|
||||
UNNEST(changed.subscriptions) AS subscriptions
|
||||
),
|
||||
filtered_subscriptions AS (
|
||||
SELECT
|
||||
subscriptions.external_id,
|
||||
)
|
||||
-- Main query to select all records from subscriptions_v1 that have been updated since the last sync
|
||||
SELECT
|
||||
subscriptions.external_id,
|
||||
-- Reconstruct the subscriptions array to include only entries with non-null timestamps greater than max_timestamp
|
||||
ARRAY(
|
||||
SELECT AS STRUCT
|
||||
subscriptions_array.subscription_name AS subscription_name,
|
||||
subscriptions_array.firefox_subscription_id AS firefox_subscription_id,
|
||||
subscriptions_array.mozilla_subscription_id AS mozilla_subscription_id,
|
||||
subscriptions_array.mozilla_dev_subscription_id AS mozilla_dev_subscription_id,
|
||||
subscriptions_array.subscription_state AS subscription_state,
|
||||
subscriptions_array.update_timestamp AS update_timestamp
|
||||
FROM
|
||||
UNNEST(subscriptions.subscriptions) AS subscriptions_array
|
||||
WHERE
|
||||
subscriptions_array.update_timestamp > max_update.latest_subscription_updated_at
|
||||
AND subscriptions_array.update_timestamp IS NOT NULL
|
||||
) AS subscriptions
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_derived.subscriptions_v1` AS subscriptions,
|
||||
max_update
|
||||
-- Filter to include only those rows where the new subscriptions array is not empty
|
||||
WHERE
|
||||
ARRAY_LENGTH(
|
||||
ARRAY(
|
||||
SELECT AS STRUCT
|
||||
subscriptions_array.subscription_name AS subscription_name,
|
||||
subscriptions_array.firefox_subscription_id AS firefox_subscription_id,
|
||||
subscriptions_array.mozilla_subscription_id AS mozilla_subscription_id,
|
||||
subscriptions_array.mozilla_dev_subscription_id AS mozilla_dev_subscription_id,
|
||||
subscriptions_array.subscription_state AS subscription_state,
|
||||
subscriptions_array.update_timestamp AS update_timestamp
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
UNNEST(subscriptions.subscriptions) AS subscriptions_array
|
||||
WHERE
|
||||
subscriptions_array.update_timestamp > max_update_timestamp.latest_subscription_updated_at
|
||||
subscriptions_array.update_timestamp > max_update.latest_subscription_updated_at
|
||||
AND subscriptions_array.update_timestamp IS NOT NULL
|
||||
) AS subscriptions
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_derived.subscriptions_v1` AS subscriptions
|
||||
CROSS JOIN
|
||||
max_update_timestamp
|
||||
)
|
||||
SELECT
|
||||
external_id,
|
||||
subscriptions
|
||||
FROM
|
||||
filtered_subscriptions
|
||||
WHERE
|
||||
ARRAY_LENGTH(subscriptions) > 0;
|
||||
)
|
||||
) > 0;
|
||||
|
|
|
@ -1,44 +1,47 @@
|
|||
|
||||
-- Construct the JSON payload in Braze required format
|
||||
SELECT
|
||||
CURRENT_TIMESTAMP() AS UPDATED_AT,
|
||||
changed_users.external_id AS EXTERNAL_ID,
|
||||
external_id AS EXTERNAL_ID,
|
||||
TO_JSON(
|
||||
STRUCT(
|
||||
email AS email,
|
||||
email_subscribe AS email_subscribe,
|
||||
ARRAY_AGG(
|
||||
STRUCT(
|
||||
changed_users.email AS email,
|
||||
changed_users.mailing_country AS mailing_country,
|
||||
changed_users.email_subscribe AS email_subscribe,
|
||||
changed_users.basket_token AS basket_token,
|
||||
changed_users.email_lang AS email_lang,
|
||||
changed_users.has_fxa AS has_fxa,
|
||||
changed_users.fxa_primary_email AS fxa_primary_email,
|
||||
changed_users.fxa_lang AS fxa_lang,
|
||||
changed_users.fxa_first_service AS fxa_first_service,
|
||||
changed_users.fxa_created_at AS fxa_created_at,
|
||||
-- braze required format for nested timestamps
|
||||
mailing_country AS mailing_country,
|
||||
basket_token AS basket_token,
|
||||
email_lang AS email_lang,
|
||||
has_fxa AS has_fxa,
|
||||
fxa_primary_email AS fxa_primary_email,
|
||||
fxa_lang AS fxa_lang,
|
||||
fxa_first_service AS fxa_first_service,
|
||||
CASE
|
||||
WHEN fxa_created_at IS NOT NULL
|
||||
THEN STRUCT(
|
||||
FORMAT_TIMESTAMP('%Y-%m-%d %H:%M:%E6S UTC', fxa_created_at, 'UTC') AS `$time`
|
||||
)
|
||||
ELSE STRUCT(
|
||||
FORMAT_TIMESTAMP(
|
||||
'%Y-%m-%d %H:%M:%E6S UTC',
|
||||
'1900-01-01 00:00:00.000000 UTC',
|
||||
'UTC'
|
||||
) AS `$time`
|
||||
)
|
||||
END AS fxa_created_at,
|
||||
STRUCT(
|
||||
FORMAT_TIMESTAMP(
|
||||
'%Y-%m-%d %H:%M:%E6S UTC',
|
||||
changed_users.create_timestamp,
|
||||
'UTC'
|
||||
) AS `$time`
|
||||
) AS create_timestamp,
|
||||
FORMAT_TIMESTAMP('%Y-%m-%d %H:%M:%E6S UTC', create_timestamp, 'UTC') AS `$time`
|
||||
) AS created_at,
|
||||
STRUCT(
|
||||
FORMAT_TIMESTAMP(
|
||||
'%Y-%m-%d %H:%M:%E6S UTC',
|
||||
changed_users.update_timestamp,
|
||||
'UTC'
|
||||
) AS `$time`
|
||||
) AS update_timestamp
|
||||
FORMAT_TIMESTAMP('%Y-%m-%d %H:%M:%E6S UTC', update_timestamp, 'UTC') AS `$time`
|
||||
) AS updated_at
|
||||
)
|
||||
ORDER BY
|
||||
changed_users.update_timestamp DESC
|
||||
) AS user_attributes_v1
|
||||
)
|
||||
) AS PAYLOAD
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_external.changed_users_v1` AS changed_users
|
||||
WHERE
|
||||
changed_users.status = 'Changed'
|
||||
`moz-fx-data-shared-prod.braze_derived.users_v1`
|
||||
GROUP BY
|
||||
changed_users.external_id;
|
||||
external_id,
|
||||
email,
|
||||
email_subscribe;
|
||||
|
|
|
@ -1,3 +1,4 @@
|
|||
-- Compares users from the previous run to detect changes to sync
|
||||
SELECT
|
||||
COALESCE(current_users.external_id, previous_users.external_id) AS external_id,
|
||||
CASE
|
||||
|
|
|
@ -1,11 +1,15 @@
|
|||
-- Retrieves the maximum newsletter updated timestamp from the last run to only
|
||||
-- select recently changed records
|
||||
WITH max_update AS (
|
||||
SELECT
|
||||
MAX(UPDATED_AT) AS max_update_timestamp
|
||||
MAX(
|
||||
TIMESTAMP(JSON_VALUE(payload.waitlists_v1[0].update_timestamp, '$."$time"'))
|
||||
) AS latest_waitlist_updated_at
|
||||
FROM
|
||||
`moz-fx-data-shared-prod.braze_external.changed_waitlists_sync_v1`
|
||||
LIMIT
|
||||
1
|
||||
)
|
||||
-- Construct the JSON payload in Braze required format
|
||||
-- Construct the JSON payload in Braze required format
|
||||
SELECT
|
||||
CURRENT_TIMESTAMP() AS UPDATED_AT,
|
||||
waitlists.external_id AS EXTERNAL_ID,
|
||||
|
@ -25,14 +29,14 @@ SELECT
|
|||
waitlists_array.create_timestamp,
|
||||
'UTC'
|
||||
) AS `$time`
|
||||
) AS create_timestamp,
|
||||
) AS created_at,
|
||||
STRUCT(
|
||||
FORMAT_TIMESTAMP(
|
||||
'%Y-%m-%d %H:%M:%E6S UTC',
|
||||
waitlists_array.update_timestamp,
|
||||
'UTC'
|
||||
) AS `$time`
|
||||
) AS update_timestamp
|
||||
) AS updated_at
|
||||
)
|
||||
ORDER BY
|
||||
waitlists_array.update_timestamp DESC
|
||||
|
@ -44,6 +48,6 @@ FROM
|
|||
CROSS JOIN
|
||||
UNNEST(waitlists.waitlists) AS waitlists_array
|
||||
WHERE
|
||||
waitlists_array.update_timestamp > (SELECT max_update_timestamp FROM max_update)
|
||||
waitlists_array.update_timestamp > (SELECT latest_waitlist_updated_at FROM max_update)
|
||||
GROUP BY
|
||||
waitlists.external_id;
|
||||
|
|
|
@ -1,3 +1,4 @@
|
|||
-- Construct the JSON payload in Braze required format
|
||||
SELECT
|
||||
CURRENT_TIMESTAMP() AS UPDATED_AT,
|
||||
external_id AS EXTERNAL_ID
|
||||
|
|
|
@ -1 +0,0 @@
|
|||
# datetime_util.fxa_parse_date
|
|
@ -1,4 +0,0 @@
|
|||
description: |
|
||||
Function for converting a datetime or date string
|
||||
in various formats into a date object
|
||||
friendly_name: fxa_parse_date
|
|
@ -1,34 +0,0 @@
|
|||
CREATE OR REPLACE FUNCTION datetime_util.fxa_parse_date(date_string STRING)
|
||||
RETURNS DATE AS (
|
||||
CASE
|
||||
WHEN REGEXP_CONTAINS(date_string, r"^(\d{4}-\d{2}-\d{2}T\d{2}:\d{2}:\d{2}\.\d{1,3}Z)$")
|
||||
THEN DATE(DATETIME(SPLIT(date_string, ".")[OFFSET(0)]))
|
||||
WHEN REGEXP_CONTAINS(date_string, r"^(\d{2}/\d{2}/\d{4}\s\d{2}:\d{2}\s(AM|PM))$")
|
||||
THEN DATE(PARSE_DATETIME("%m/%d/%Y %I:%M %p", date_string))
|
||||
WHEN REGEXP_CONTAINS(date_string, r"^(\d{2}/\d{2}/\d{4}\s\d{2}:\d{2}:\d{3})$")
|
||||
THEN DATE(PARSE_DATETIME("%m/%d/%Y", SPLIT(date_string, " ")[OFFSET(0)]))
|
||||
WHEN REGEXP_CONTAINS(date_string, r"^(\d{2}/\d{2}/\d{4}\s\d{2}:\d{2}:\d{2})$")
|
||||
THEN DATE(PARSE_DATETIME("%m/%d/%Y", SPLIT(date_string, " ")[OFFSET(0)]))
|
||||
WHEN REGEXP_CONTAINS(date_string, r"^(\d{2}/\d{2}/\d{4})$")
|
||||
THEN PARSE_DATE("%m/%d/%Y", date_string)
|
||||
WHEN REGEXP_CONTAINS(date_string, r"^(\d{4}/\d{2}/\d{2})$")
|
||||
THEN PARSE_DATE("%Y/%m/%d", date_string)
|
||||
ELSE DATE(NULLIF(date_string, ''))
|
||||
END
|
||||
);
|
||||
|
||||
-- Tests
|
||||
SELECT
|
||||
assert.equals(DATE("2021-01-01"), mozfun.datetime_util.fxa_parse_date("2021-01-01")),
|
||||
assert.equals(DATE("2021-01-01"), mozfun.datetime_util.fxa_parse_date("2021/01/01")),
|
||||
assert.equals(DATE("2020-09-23"), mozfun.datetime_util.fxa_parse_date("09/23/2020")),
|
||||
assert.equals(DATE("2017-04-23"), mozfun.datetime_util.fxa_parse_date("04/23/2017")),
|
||||
assert.equals(DATE("2022-04-21"), mozfun.datetime_util.fxa_parse_date("2022-04-21 12:43:34 UTC")),
|
||||
assert.equals(
|
||||
DATE("2022-04-21"),
|
||||
mozfun.datetime_util.fxa_parse_date("2022-04-21 12:44:36.707000 UTC")
|
||||
),
|
||||
assert.equals(DATE("2022-04-21"), mozfun.datetime_util.fxa_parse_date("04/21/2022 09:36 PM")),
|
||||
assert.equals(DATE("2022-04-21"), mozfun.datetime_util.fxa_parse_date("04/21/2022 09:36 AM")),
|
||||
assert.equals(DATE("2022-02-28"), mozfun.datetime_util.fxa_parse_date("02/28/2022 03:33:172")),
|
||||
assert.equals(DATE("2022-04-13"), mozfun.datetime_util.fxa_parse_date("04/13/2022 21:13:54")),
|
|
@ -1,4 +1,4 @@
|
|||
# expect braze subscriptions
|
||||
# test_braze_subscriptions - expect braze subscriptions
|
||||
---
|
||||
# user 1
|
||||
- external_id: user_1
|
||||
|
@ -33,21 +33,6 @@
|
|||
mozilla_dev_subscription_id: mozilla_dev_waitlist_1
|
||||
subscription_state: subscribed
|
||||
update_timestamp: 2020-01-01T11:00:00+00:00
|
||||
- subscription_name: waitlist_2-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_2
|
||||
mozilla_subscription_id: mozilla_waitlist_2
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_2
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: waitlist_3-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_3
|
||||
mozilla_subscription_id: mozilla_waitlist_3
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_3
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: waitlist_4-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_4
|
||||
mozilla_subscription_id: mozilla_waitlist_4
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_4
|
||||
subscription_state: unsubscribed
|
||||
# user 2
|
||||
- external_id: user_2
|
||||
subscriptions:
|
||||
|
@ -57,42 +42,12 @@
|
|||
mozilla_dev_subscription_id: mozilla_dev_newsletter_1
|
||||
subscription_state: subscribed
|
||||
update_timestamp: 2020-02-01T10:00:00+00:00
|
||||
- subscription_name: newsletter_2
|
||||
firefox_subscription_id: firefox_newsletter_2
|
||||
mozilla_subscription_id: mozilla_newsletter_2
|
||||
mozilla_dev_subscription_id: mozilla_dev_newsletter_2
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: newsletter_3
|
||||
firefox_subscription_id: firefox_newsletter_3
|
||||
mozilla_subscription_id: mozilla_newsletter_3
|
||||
mozilla_dev_subscription_id: mozilla_dev_newsletter_3
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: newsletter_4
|
||||
firefox_subscription_id: firefox_newsletter_4
|
||||
mozilla_subscription_id: mozilla_newsletter_4
|
||||
mozilla_dev_subscription_id: mozilla_dev_newsletter_4
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: waitlist_1-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_1
|
||||
mozilla_subscription_id: mozilla_waitlist_1
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_1
|
||||
subscription_state: subscribed
|
||||
update_timestamp: 2020-02-01T11:00:00+00:00
|
||||
- subscription_name: waitlist_2-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_2
|
||||
mozilla_subscription_id: mozilla_waitlist_2
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_2
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: waitlist_3-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_3
|
||||
mozilla_subscription_id: mozilla_waitlist_3
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_3
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: waitlist_4-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_4
|
||||
mozilla_subscription_id: mozilla_waitlist_4
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_4
|
||||
subscription_state: unsubscribed
|
||||
# user 3
|
||||
- external_id: user_3
|
||||
subscriptions:
|
||||
|
@ -102,40 +57,9 @@
|
|||
mozilla_dev_subscription_id: mozilla_dev_newsletter_1
|
||||
subscription_state: subscribed
|
||||
update_timestamp: 2020-03-01T10:00:00+00:00
|
||||
- subscription_name: newsletter_2
|
||||
firefox_subscription_id: firefox_newsletter_2
|
||||
mozilla_subscription_id: mozilla_newsletter_2
|
||||
mozilla_dev_subscription_id: mozilla_dev_newsletter_2
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: newsletter_3
|
||||
firefox_subscription_id: firefox_newsletter_3
|
||||
mozilla_subscription_id: mozilla_newsletter_3
|
||||
mozilla_dev_subscription_id: mozilla_dev_newsletter_3
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: newsletter_4
|
||||
firefox_subscription_id: firefox_newsletter_4
|
||||
mozilla_subscription_id: mozilla_newsletter_4
|
||||
mozilla_dev_subscription_id: mozilla_dev_newsletter_4
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: waitlist_1-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_1
|
||||
mozilla_subscription_id: mozilla_waitlist_1
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_1
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: waitlist_2-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_2
|
||||
mozilla_subscription_id: mozilla_waitlist_2
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_2
|
||||
subscription_state: subscribed
|
||||
update_timestamp: 2020-03-02T11:00:00+00:00
|
||||
- subscription_name: waitlist_3-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_3
|
||||
mozilla_subscription_id: mozilla_waitlist_3
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_3
|
||||
subscription_state: unsubscribed
|
||||
- subscription_name: waitlist_4-waitlist
|
||||
firefox_subscription_id: firefox_waitlist_4
|
||||
mozilla_subscription_id: mozilla_waitlist_4
|
||||
mozilla_dev_subscription_id: mozilla_dev_waitlist_4
|
||||
subscription_state: unsubscribed
|
||||
# user 4 not in braze_users
|
||||
|
|
|
@ -1,4 +1,4 @@
|
|||
# braze subscription map
|
||||
# test_braze_subscriptions - braze subscription map
|
||||
---
|
||||
- braze_subscription_name: newsletter_1
|
||||
firefox_subscription_id: firefox_newsletter_1
|
||||
|
|
|
@ -1,4 +1,4 @@
|
|||
# braze user profiles w/ newsletter and waitlist data
|
||||
# test_braze_subscriptions - braze user profiles w/ newsletter and waitlist data
|
||||
---
|
||||
# user 1
|
||||
- external_id: user_1
|
||||
|
@ -46,12 +46,3 @@
|
|||
subscribed: true
|
||||
update_timestamp: 2020-03-11 11:00:00+00:00
|
||||
# user 4 not in braze_users
|
||||
- external_id: not_a_user
|
||||
newsletters:
|
||||
- newsletter_name: newsletter_1
|
||||
subscribed: true
|
||||
update_timestamp: 2020-04-01 10:00:00+00:00
|
||||
waitlists:
|
||||
- waitlist_name: waitlist_1
|
||||
subscribed: true
|
||||
update_timestamp: 2020-04-11 11:00:00+00:00
|
||||
|
|
|
@ -1,9 +0,0 @@
|
|||
# braze users
|
||||
---
|
||||
# user 1
|
||||
- external_id: user_1
|
||||
# user 2
|
||||
- external_id: user_2
|
||||
# user 3
|
||||
- external_id: user_3
|
||||
# user 4 not in braze_users
|
|
@ -1,4 +1,4 @@
|
|||
# expect for braze waitlists
|
||||
# tets_braze_waitlists - expect
|
||||
---
|
||||
# user 1
|
||||
- external_id: user_1
|
||||
|
@ -28,3 +28,4 @@
|
|||
unsub_reason: for reasons
|
||||
update_timestamp: 2021-01-01 13:00:00+00:00
|
||||
# user 2 unsubscribed from two waitlists
|
||||
# user 3 not on waitlists
|
||||
|
|
|
@ -0,0 +1,8 @@
|
|||
# test_braze_waitlists - users
|
||||
---
|
||||
# user 1
|
||||
- external_id: user_1
|
||||
# user 2 unsubscribed from two waitlists
|
||||
- external_id: user_2
|
||||
# user 3 not on waitlists
|
||||
- external_id: user_3
|
|
@ -1,4 +1,4 @@
|
|||
# waitlists
|
||||
# test_braze_waitlists - ctms_waitlists
|
||||
---
|
||||
# user 1
|
||||
- email_id: user_1
|
||||
|
@ -16,7 +16,7 @@
|
|||
name: waitlist_2
|
||||
fields: '{
|
||||
"geo": "DE",
|
||||
"platform": "platform_2"
|
||||
"platform": "Platform_2"
|
||||
}'
|
||||
source: source_2
|
||||
create_timestamp: 2020-01-01 10:00:00+00:00
|
||||
|
@ -29,7 +29,7 @@
|
|||
"geo": "DE",
|
||||
"platform": "platform_3"
|
||||
}'
|
||||
source: source_3
|
||||
source: Source_3
|
||||
create_timestamp: 2020-01-01 10:00:00+00:00
|
||||
subscribed: false
|
||||
unsub_reason: for reasons
|
||||
|
|
Загрузка…
Ссылка в новой задаче