Skip to content

Commit

Permalink
Fields designed to show how customers behave and how long they stick …
Browse files Browse the repository at this point in the history
…around paying.
  • Loading branch information
JonCrawford committed Jul 12, 2024
1 parent 7644b63 commit fb7dc53
Show file tree
Hide file tree
Showing 4 changed files with 111 additions and 6 deletions.
36 changes: 36 additions & 0 deletions models/mesa/marts/_shops.yml
Original file line number Diff line number Diff line change
Expand Up @@ -704,6 +704,8 @@ models:
name: workflow_run_stop_rolling_thirty_day_count
- description: The number of workflow runs that have resulted in Failure.
name: workflow_runs_fail_count
data_tests:
- not_null
- description:
The number of workflow runs that have resulted in Failure in the
last 30 days.
Expand Down Expand Up @@ -914,3 +916,37 @@ models:
description: The timestamp of when we sent the Shop a request to review MESA in the app store in Pacific Time.
- name: has_app_store_reviewed
description: Whether the Shop has reviewed MESA in the app store.
- name: has_taken_billing_breaks
description: Indicates if there's been a gap between days that the merchant has been billed, usually meaning they uninstalled and later reinstalled the app.
data_tests:
- not_null
- accepted_values:
values: [true, false]
- name: billing_break_days
description: >
The total number of days without billing, including a 7-day detection period for each break.
This accounts for the rolling 7-day window used to determine revenue periods.
NULL if the shop has never been billed or has no billing breaks.
tests:
- dbt_utils.accepted_range:
min_value: 8
inclusive: true
where: "billing_break_days is not null"
- name: billing_breaks
description: A JSON array representation of all billing breaks, including start date, end date, and duration of each break. NULL if the shop has never been billed.
- name: paid_days_completed_tier
description: A categorization of the number of paid days completed, providing insight into customer retention at different stages. NULL if the shop has never been billed.
data_tests:
- accepted_values:
values:
[
NULL,
"A-1 day",
"B-2-7 days",
"C-8-30 days",
"D-31-60 days",
"E-61-90 days",
"F-91-180 days",
"G-181-365 days",
"H-365+ days",
]
75 changes: 72 additions & 3 deletions models/mesa/marts/shops.sql
Original file line number Diff line number Diff line change
Expand Up @@ -489,7 +489,6 @@ churn_types AS (
churn_dates AS (
SELECT
shop_subdomain,
{# day_before_inc_amount, #}
MAX(dt) AS churned_on_pt
FROM shops
LEFT JOIN inc_amount_days_and_day_befores USING (shop_subdomain)
Expand All @@ -502,6 +501,72 @@ churn_dates AS (
GROUP BY 1, uninstalled_at_pt
),

daily_revenue AS (
SELECT
shop_subdomain,
dt,
inc_amount,
SUM(inc_amount) OVER (PARTITION BY shop_subdomain ORDER BY dt ROWS BETWEEN 6 PRECEDING AND CURRENT ROW) AS rolling_7_day_revenue
FROM {{ ref('int_mesa_shop_days') }}
),

revenue_periods AS (
SELECT
shop_subdomain,
dt,
inc_amount,
rolling_7_day_revenue,
CASE
WHEN rolling_7_day_revenue > 0 THEN 1
ELSE 0
END AS is_revenue_period,
SUM(CASE WHEN rolling_7_day_revenue > 0 THEN 1 ELSE 0 END) OVER (PARTITION BY shop_subdomain ORDER BY dt) AS revenue_period_group
FROM daily_revenue
),

billing_breaks AS (
SELECT
shop_subdomain,
MIN(dt) AS start_date,
MAX(dt) AS end_date,
DATEDIFF(day, MIN(dt), MAX(dt)) + 1 AS days
FROM revenue_periods
WHERE is_revenue_period = 0
GROUP BY shop_subdomain, revenue_period_group
HAVING days > 7 -- Only consider breaks longer than a week
),

shop_billing_breaks AS (
SELECT
shop_subdomain,
ARRAY_AGG(OBJECT_CONSTRUCT(
'start', DATEADD('day', -7, start_date), -- Adjust start date
'end', end_date,
'days', days + 7 -- Add 7 days to the break duration
)) AS billing_breaks,
NULLIF(SUM(days + 7), 7) AS billing_break_days, -- Add 7 days to each break
COUNT(*) > 0 AS has_taken_billing_breaks
FROM billing_breaks
GROUP BY shop_subdomain
),

paid_days_tiers AS (
SELECT
shop_subdomain,
CASE
WHEN paid_days_completed = 0 THEN NULL
WHEN paid_days_completed = 1 THEN 'A-1 day'
WHEN paid_days_completed BETWEEN 2 AND 7 THEN 'B-2-7 days'
WHEN paid_days_completed BETWEEN 8 AND 30 THEN 'C-8-30 days'
WHEN paid_days_completed BETWEEN 31 AND 60 THEN 'D-31-60 days'
WHEN paid_days_completed BETWEEN 61 AND 90 THEN 'E-61-90 days'
WHEN paid_days_completed BETWEEN 91 AND 180 THEN 'F-91-180 days'
WHEN paid_days_completed BETWEEN 181 AND 365 THEN 'G-181-365 days'
WHEN paid_days_completed > 365 THEN 'H-365+ days'
END AS paid_days_completed_tier
FROM shops
),

final AS (
SELECT
*
Expand All @@ -518,7 +583,9 @@ final AS (
COALESCE((1.0 * shopify_shop_gmv_initial_total_usd) >= 3000, FALSE)
OR
shopify_plan_name IN ('professional', 'unlimited', 'shopify_plus')
) AS is_mql
) AS is_mql,
COALESCE(shop_billing_breaks.has_taken_billing_breaks, FALSE) AS has_taken_billing_breaks,
COALESCE(shop_billing_breaks.billing_break_days, NULL) AS billing_break_days
),
NOT activation_date_pt IS NULL AS is_activated,
IFF(is_activated, 'activated', 'onboarding') AS funnel_phase,
Expand Down Expand Up @@ -702,7 +769,6 @@ final AS (
COALESCE(
iff(projected_mrr > 0, projected_mrr, iff(last_plan_price > 0, last_plan_price, plan_price)), 0
) AS shop_value_per_month

FROM shops
LEFT JOIN billing_accounts USING (shop_subdomain)
LEFT JOIN price_per_actions USING (shop_subdomain)
Expand Down Expand Up @@ -733,6 +799,9 @@ final AS (
LEFT JOIN churn_types USING (shop_subdomain)
LEFT JOIN workflow_source_destination_pairs USING (shop_subdomain)
LEFT JOIN last_plan_prices USING (shop_subdomain)
LEFT JOIN shop_billing_breaks USING (shop_subdomain)
LEFT JOIN paid_days_tiers USING (shop_subdomain)

)

SELECT *
Expand Down
4 changes: 2 additions & 2 deletions package-lock.yml
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,7 @@ packages:
- package: calogica/dbt_expectations
version: 0.10.3
- package: dbt-labs/dbt_utils
version: 1.1.1
version: 1.2.0
- package: Fleetio/dbt_segment
version: 0.3.1
sha1_hash: c2f8a36e447aee89cb9e1934785b4c8cab91c92e
sha1_hash: 4a701920808227fdd220c4a4490177435635126e
2 changes: 1 addition & 1 deletion packages.yml
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ packages:
#- package: tnightengale/dbt_meta_testing
# version: 0.3.6
- package: dbt-labs/dbt_utils
version: [">=1.1.1"]
version: [">=1.2.0"]
#- git: "https://github.com/JonCrawford/dbt_segment"
# warn-unpinned: false
- package: Fleetio/dbt_segment
Expand Down

0 comments on commit fb7dc53

Please sign in to comment.