Skip to content

Commit

Permalink
Merge pull request #3 from TasmanAnalytics/feature/mrr-improvements
Browse files Browse the repository at this point in the history
✨ Improve mrr accuracy
  • Loading branch information
jurrigerretsen authored Feb 22, 2024
2 parents 982e56f + 002960c commit 1d1cb15
Show file tree
Hide file tree
Showing 3 changed files with 50 additions and 11 deletions.
2 changes: 1 addition & 1 deletion models/analysis/_analysis.yml
Original file line number Diff line number Diff line change
Expand Up @@ -235,7 +235,7 @@ models:
source_model: "{{ var('revenuecat_mrr_test_seed') }}"
source_date: report_date
source_metric: mrr
percent_mismatch_threshold: 0.1
percent_mismatch_threshold: "{{ var('revenuecat_mrr_test_threshold', 1) }}"

- name: platform
data_type: varchar
Expand Down
19 changes: 15 additions & 4 deletions models/analysis/revenuecat_monthly_recurring_revenue.sql
Original file line number Diff line number Diff line change
@@ -1,8 +1,14 @@
with

subscription_transactions as (
select * from {{ ref('revenuecat_subscription_transactions') }} where valid_to is null
),
select * from {{ ref('revenuecat_subscription_transactions') }}
where
valid_to is null
and is_trial_period = false
and ownership_type != 'FAMILY_SHARED'
and datediff('s', start_time, expected_end_time)::float > 0
and store != 'promotional'
),

date_spine as (
select distinct date_month from {{ ref('revenuecat_date_spine') }}
Expand Down Expand Up @@ -44,8 +50,13 @@ final as (

left join
transaction_monthly_revenue
on date_spine.date_month >= transaction_monthly_revenue.start_time::date
and last_day(date_spine.date_month, month) <= last_day(transaction_monthly_revenue.effective_end_time::date, month)
on transaction_monthly_revenue.start_time::date <= last_day(date_month, month)
and case
when transaction_monthly_revenue.effective_end_time >= convert_timezone('America/Los_Angeles', 'UTC', convert_timezone('UTC', current_timestamp)::date) -- Assumes that RevenueCat runs their data model at this time. This gives an 99.9% accurate MRR number for the current month & prior months
then transaction_monthly_revenue.effective_end_time::date > date_spine.date_month
else transaction_monthly_revenue.effective_end_time::date > last_day(date_spine.date_month, month)
end


group by
date_spine.date_month,
Expand Down
40 changes: 34 additions & 6 deletions models/core/revenuecat_subscription_transactions.sql
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
{{
config(
materialized = 'incremental',
unique_key = 'row_id',
unique_key = 'transaction_row_id',
)
}}

Expand Down Expand Up @@ -50,11 +50,39 @@ renamed as (
price_in_usd * tax_percentage as estimated_tax_in_usd,
price_in_usd - commission_in_usd - estimated_tax_in_usd as proceeds_in_usd,
-- Documentation for normalizing mrr_in_usd: https://docs.revenuecat.com/docs/monthly-recurring-revenue-mrr_in_usd-chart
case
when product_duration = 'P1M' then price_in_usd
when product_duration = 'P1Y' then price_in_usd / 12
when product_duration = 'P1W' then price_in_usd * 4
else 0
case
when effective_end_time is not null then
case
/* handle cases where product_duration cannot be used for the transaction first */
when (is_in_intro_offer_period = 'true' or product_duration is null)
then
case
when datediff(day, start_time, expected_end_time) between 0 and 1 then round(30 * price_in_usd, 2)
when datediff(day, start_time, expected_end_time) = 3 then round(10 * price_in_usd, 2)
when datediff(day, start_time, expected_end_time) between 6 and 8 then round(4 * price_in_usd, 2)
when datediff(day, start_time, expected_end_time) between 12 and 16 then round(2 * price_in_usd, 2)
when datediff(day, start_time, expected_end_time) between 27 and 33 then round(1 * price_in_usd, 2)
when datediff(day, start_time, expected_end_time) between 58 and 62 then round(0.5 * price_in_usd, 2)
when datediff(day, start_time, expected_end_time) between 88 and 95 then round(0.333333 * price_in_usd, 2)
when datediff(day, start_time, expected_end_time) between 179 and 185 then round(0.1666666 * price_in_usd, 2)
when datediff(day, start_time, expected_end_time) between 363 and 375 then round(0.08333 * price_in_usd, 2)
else round(((28 / (datediff('s', start_time, expected_end_time) / (24 * 3600))) * price_in_usd), 2)
end
/* then handle cases where product_duration can be used */
when product_duration = 'P1D' then round(30 * price_in_usd, 2)
when product_duration = 'P3D' then round(10 * price_in_usd, 2)
when product_duration = 'P7D' then round(4 * price_in_usd, 2)
when product_duration = 'P1W' then round(4 * price_in_usd, 2)
when product_duration = 'P2W' then round(2 * price_in_usd, 2)
when product_duration = 'P4W' then round(1 * price_in_usd, 2)
when product_duration = 'P1M' then round(1 * price_in_usd, 2)
when product_duration = 'P2M' then round(0.5 * price_in_usd, 2)
when product_duration = 'P3M' then round(0.333333 * price_in_usd, 2)
when product_duration = 'P6M' then round(0.1666666 * price_in_usd, 2)
when product_duration = 'P12M' then round(0.08333 * price_in_usd, 2)
when product_duration = 'P1Y' then round(0.08333 * price_in_usd, 2)
else round(((28 / (datediff('s', start_time, expected_end_time) / (24 * 3600))) * price_in_usd), 2)
end
end as mrr_in_usd,
takehome_percentage,

Expand Down

0 comments on commit 1d1cb15

Please sign in to comment.