Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

[DS-3326] Add state to subplat subscriptions v2 #5836

Open
wants to merge 7 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from 6 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -51,6 +51,10 @@ fields:
- name: country_name
type: STRING
mode: NULLABLE
- name: state_code
type: STRING
mode: NULLABLE
description: Two-letter state/province code (only for US and Canada).
- name: services
type: RECORD
mode: REPEATED
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -57,6 +57,10 @@ fields:
- name: country_name
type: STRING
mode: NULLABLE
- name: state_code
type: STRING
mode: NULLABLE
description: Two-letter state/province code (only for US and Canada).
- name: services
type: RECORD
mode: REPEATED
Expand Down Expand Up @@ -241,6 +245,10 @@ fields:
- name: country_name
type: STRING
mode: NULLABLE
- name: state_code
type: STRING
mode: NULLABLE
description: Two-letter state/province code (only for US and Canada).
- name: services
type: RECORD
mode: REPEATED
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -146,6 +146,7 @@ SELECT
) AS customer_subscription_number,
history.subscription.country_code,
COALESCE(countries.name, history.subscription.country_code, 'Unknown') AS country_name,
history.subscription.state_code,
history.subscription.services,
history.subscription.provider_product_id,
history.subscription.product_name,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -54,6 +54,10 @@ fields:
- name: country_name
type: STRING
mode: NULLABLE
- name: state_code
type: STRING
mode: NULLABLE
description: Two-letter state/province code (only for US and Canada).
- name: services
type: RECORD
mode: REPEATED
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -54,6 +54,10 @@ fields:
- name: country_name
type: STRING
mode: NULLABLE
- name: state_code
type: STRING
mode: NULLABLE
description: Two-letter state/province code (only for US and Canada).
- name: services
type: RECORD
mode: REPEATED
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,8 @@ description: |-

This table's schema closely mirrors Stripe's customers API (https://stripe.com/docs/api/customers/object).
Fields which Fivetran doesn't sync and fields we've specifically chosen not to include (e.g. PII) have been omitted.
In particular, all address fields except country have been omitted because Firefox Account user IDs are present and this is in a Mozilla-confidential dataset.
In particular, all address fields except country and state have been omitted because Firefox Account user IDs
are present and this is in a Mozilla-confidential dataset.
owners:
- srose@mozilla.com
labels:
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -38,6 +38,10 @@ fields:
type: STRING
mode: NULLABLE
description: Two-letter country code (ISO 3166-1 alpha-2).
- name: state
type: STRING
mode: NULLABLE
description: Two-letter state/province code (only for US and Canada).
- name: created
type: TIMESTAMP
mode: NULLABLE
Expand Down Expand Up @@ -200,6 +204,10 @@ fields:
type: STRING
mode: NULLABLE
description: Two-letter country code (ISO 3166-1 alpha-2).
- name: state
type: STRING
mode: NULLABLE
description: Two-letter state/province code (only for US and Canada).
- name: tax_exempt
type: STRING
mode: NULLABLE
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,8 @@ description: |-

This table's schema closely mirrors Stripe's customers API (https://stripe.com/docs/api/customers/object).
Fields which Fivetran doesn't sync and fields we've specifically chosen not to include (e.g. PII) have been omitted.
In particular, all address fields except country have been omitted because Firefox Account user IDs are present and this is in a Mozilla-confidential dataset.
In particular, all address fields except country and state have been omitted because Firefox Account user IDs
are present and this is in a Mozilla-confidential dataset.
owners:
- srose@mozilla.com
labels:
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -40,18 +40,69 @@ WITH original_changelog AS (
JSON_VALUE(customer.metadata.userid) AS userid,
TO_HEX(SHA256(JSON_VALUE(customer.metadata.userid))) AS userid_sha256
) AS metadata,
-- Limit address data to just country since the metadata includes FxA user IDs
-- and this is in a Mozilla-confidential dataset.
STRUCT(customer.address.country) AS address,
-- Limit address data to country and state since the metadata includes FxA user IDs
-- and this is in a Mozilla-confidential dataset. State is only for US and Canada.
STRUCT(
NULLIF(customer.address.country, ""),
Copy link
Contributor

Choose a reason for hiding this comment

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

Suggested change
NULLIF(customer.address.country, ""),
NULLIF(customer.address.country, "") AS country,

IF(
customer.address.country IN ("US", "CA"),
COALESCE(
-- Only use two-letter codes for consistency since billing addresses sometimes have full names
IF(LENGTH(customer.address.state) = 2, customer.address.state, NULL),
us_zip_code_prefixes.state_code,
ca_postal_districts.province_code
),
NULL
) AS state
) AS address,
(
SELECT AS STRUCT
customer.shipping.* REPLACE (STRUCT(customer.shipping.address.country) AS address)
customer.shipping.* REPLACE (
STRUCT(
NULLIF(customer.shipping.address.country, ""),
Copy link
Contributor

Choose a reason for hiding this comment

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

Suggested change
NULLIF(customer.shipping.address.country, ""),
NULLIF(customer.shipping.address.country, "") AS country,

IF(
customer.shipping.address.country IN ("US", "CA"),
COALESCE(
IF(
LENGTH(customer.shipping.address.state) = 2,
customer.shipping.address.state,
NULL
),
us_shipping_zip_code_prefixes.state_code,
ca_shipping_postal_districts.province_code
),
NULL
) AS state
) AS address
)
) AS shipping
)
) AS customer,
ROW_NUMBER() OVER customer_changes_asc AS customer_change_number
FROM
`moz-fx-data-shared-prod`.stripe_external.customers_changelog_v1
-- try to get state using postal code if state field is unavailable
LEFT JOIN
`moz-fx-data-shared-prod.static.us_zip_code_prefixes_v1` AS us_shipping_zip_code_prefixes
ON customer.shipping.address.country = "US"
AND LEFT(
customer.shipping.address.postal_code,
3
) = us_shipping_zip_code_prefixes.zip_code_prefix
LEFT JOIN
`moz-fx-data-shared-prod.static.us_zip_code_prefixes_v1` AS us_zip_code_prefixes
ON customer.address.country = "US"
AND LEFT(customer.address.postal_code, 3) = us_zip_code_prefixes.zip_code_prefix
LEFT JOIN
`moz-fx-data-shared-prod.static.ca_postal_districts_v1` AS ca_shipping_postal_districts
ON customer.shipping.address.country = "CA"
AND UPPER(
LEFT(customer.shipping.address.postal_code, 1)
) = ca_shipping_postal_districts.postal_district_code
LEFT JOIN
`moz-fx-data-shared-prod.static.ca_postal_districts_v1` AS ca_postal_districts
ON customer.address.country = "CA"
AND UPPER(LEFT(customer.address.postal_code, 1)) = ca_postal_districts.postal_district_code
WINDOW
customer_changes_asc AS (
PARTITION BY
Expand All @@ -68,7 +119,7 @@ pre_fivetran_changelog AS (
TIMESTAMP '2022-03-25 00:02:29' AS `timestamp`,
STRUCT(
id,
STRUCT(address.country) AS address,
STRUCT(address.country, address.state) AS address,
created,
CAST(NULL AS STRING) AS default_source_id,
CAST(
Expand Down Expand Up @@ -103,7 +154,7 @@ pre_fivetran_changelog AS (
CAST(NULL AS STRING) AS userid,
JSON_VALUE(metadata.userid_sha256) AS userid_sha256
) AS metadata,
CAST(NULL AS STRUCT<address STRUCT<country STRING>>) AS shipping,
CAST(NULL AS STRUCT<address STRUCT<country STRING, state STRING>>) AS shipping,
CAST(NULL AS STRING) AS tax_exempt
) AS customer,
1 AS customer_change_number
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -48,6 +48,10 @@ fields:
type: STRING
mode: NULLABLE
description: Two-letter country code (ISO 3166-1 alpha-2).
- name: state
type: STRING
mode: NULLABLE
description: Two-letter state/province code (only for US and Canada).
- name: created
type: TIMESTAMP
mode: NULLABLE
Expand Down Expand Up @@ -210,6 +214,10 @@ fields:
type: STRING
mode: NULLABLE
description: Two-letter country code (ISO 3166-1 alpha-2).
- name: state
type: STRING
mode: NULLABLE
description: Two-letter state/province code (only for US and Canada).
- name: tax_exempt
type: STRING
mode: NULLABLE
Expand Down
Loading