From 758e533bded2e919ff45d009c10c74d0e1f4ff69 Mon Sep 17 00:00:00 2001
From: Jurri Gerretsen <62351599+jurrigerretsen@users.noreply.github.com>
Date: Wed, 21 Feb 2024 16:01:01 +0100
Subject: [PATCH 1/4] =?UTF-8?q?=E2=9C=A8=20Improve=20mrr=20accuracy?=
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit

---
 models/analysis/_analysis.yml                 |  2 +-
 .../revenuecat_monthly_recurring_revenue.sql  | 19 ++++--
 .../revenuecat_subscription_transactions.sql  | 59 +++++++++++++++++--
 3 files changed, 69 insertions(+), 11 deletions(-)

diff --git a/models/analysis/_analysis.yml b/models/analysis/_analysis.yml
index f549131..cc1f1a5 100644
--- a/models/analysis/_analysis.yml
+++ b/models/analysis/_analysis.yml
@@ -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
diff --git a/models/analysis/revenuecat_monthly_recurring_revenue.sql b/models/analysis/revenuecat_monthly_recurring_revenue.sql
index 61f0505..bfe9f3e 100644
--- a/models/analysis/revenuecat_monthly_recurring_revenue.sql
+++ b/models/analysis/revenuecat_monthly_recurring_revenue.sql
@@ -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') }}
@@ -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', SYSDATE()::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,
diff --git a/models/core/revenuecat_subscription_transactions.sql b/models/core/revenuecat_subscription_transactions.sql
index 077eb6d..70490ea 100644
--- a/models/core/revenuecat_subscription_transactions.sql
+++ b/models/core/revenuecat_subscription_transactions.sql
@@ -1,7 +1,7 @@
 {{
   config(
     materialized = 'incremental',
-    unique_key = 'row_id',
+    unique_key = 'transaction_row_id',
     )
 }}
 
@@ -50,11 +50,58 @@ 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 (30 * price_in_usd)::decimal(18,2)
+                    when datediff(day, start_time, expected_end_time) = 3 
+                        then (10 * price_in_usd)::decimal(18,2)
+                    when datediff(day, start_time, expected_end_time) between 6 and 8 
+                        then (4 * price_in_usd)::decimal(18,2)
+                    when datediff(day, start_time, expected_end_time) between 12 and 16 
+                        then (2 * price_in_usd)::decimal(18,2)
+                    when datediff(day, start_time, expected_end_time) between 27 and 33 
+                        then (1 * price_in_usd)::decimal(18,2)
+                    when datediff(day, start_time, expected_end_time) between 58 and 62 
+                        then (0.5 * price_in_usd)::decimal(18,2)
+                    when datediff(day, start_time, expected_end_time) between 88 and 95 
+                        then (0.333333 * price_in_usd)::decimal(18,2)
+                    when datediff(day, start_time, expected_end_time) between 179 and 185 
+                        then (0.1666666 * price_in_usd)::decimal(18,2)
+                    when datediff(day, start_time, expected_end_time) between 363 and 375 
+                        then (0.08333 * price_in_usd)::decimal(18,2)
+                    else ((28 / (datediff('s', start_time, expected_end_time)::float / (24 * 3600))) * price_in_usd)::decimal(18,2)
+                end
+                /* then handle cases where product_duration can be used */
+                when product_duration = 'P1D' 
+                    then (30 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P3D' 
+                    then (10 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P7D' 
+                    then (4 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P1W' 
+                    then (4 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P2W' 
+                    then (2 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P4W' 
+                    then (1 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P1M' 
+                    then (1 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P2M' 
+                    then (0.5 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P3M' 
+                    then (0.333333 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P6M' 
+                    then (0.1666666 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P12M' 
+                    then (0.08333 * price_in_usd)::decimal(18,2)
+                when product_duration = 'P1Y' 
+                    then (0.08333 * price_in_usd)::decimal(18,2)
+                else ((28 / (datediff('s', start_time, expected_end_time)::float / (24 * 3600))) * price_in_usd)::decimal(18,2)
+            end
         end as mrr_in_usd,
         takehome_percentage,
 

From ec26fe6ef639565c022f3337f0b0489500f06cfd Mon Sep 17 00:00:00 2001
From: Jurri Gerretsen <62351599+jurrigerretsen@users.noreply.github.com>
Date: Thu, 22 Feb 2024 07:48:26 +0100
Subject: [PATCH 2/4] =?UTF-8?q?=F0=9F=8E=A8=20Removed=20database=20specifi?=
 =?UTF-8?q?c=20casting?=
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit

---
 .../revenuecat_subscription_transactions.sql  | 83 +++++++------------
 1 file changed, 32 insertions(+), 51 deletions(-)

diff --git a/models/core/revenuecat_subscription_transactions.sql b/models/core/revenuecat_subscription_transactions.sql
index 70490ea..25f55c3 100644
--- a/models/core/revenuecat_subscription_transactions.sql
+++ b/models/core/revenuecat_subscription_transactions.sql
@@ -50,58 +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 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 (30 * price_in_usd)::decimal(18,2)
-                    when datediff(day, start_time, expected_end_time) = 3 
-                        then (10 * price_in_usd)::decimal(18,2)
-                    when datediff(day, start_time, expected_end_time) between 6 and 8 
-                        then (4 * price_in_usd)::decimal(18,2)
-                    when datediff(day, start_time, expected_end_time) between 12 and 16 
-                        then (2 * price_in_usd)::decimal(18,2)
-                    when datediff(day, start_time, expected_end_time) between 27 and 33 
-                        then (1 * price_in_usd)::decimal(18,2)
-                    when datediff(day, start_time, expected_end_time) between 58 and 62 
-                        then (0.5 * price_in_usd)::decimal(18,2)
-                    when datediff(day, start_time, expected_end_time) between 88 and 95 
-                        then (0.333333 * price_in_usd)::decimal(18,2)
-                    when datediff(day, start_time, expected_end_time) between 179 and 185 
-                        then (0.1666666 * price_in_usd)::decimal(18,2)
-                    when datediff(day, start_time, expected_end_time) between 363 and 375 
-                        then (0.08333 * price_in_usd)::decimal(18,2)
-                    else ((28 / (datediff('s', start_time, expected_end_time)::float / (24 * 3600))) * price_in_usd)::decimal(18,2)
+		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 (30 * price_in_usd)
+                                when datediff(day, start_time, expected_end_time) = 3 then (10 * price_in_usd)
+                                when datediff(day, start_time, expected_end_time) between 6 and 8 then (4 * price_in_usd)
+                                when datediff(day, start_time, expected_end_time) between 12 and 16 then (2 * price_in_usd)
+                                when datediff(day, start_time, expected_end_time) between 27 and 33 then (1 * price_in_usd)
+                                when datediff(day, start_time, expected_end_time) between 58 and 62 then (0.5 * price_in_usd)
+                                when datediff(day, start_time, expected_end_time) between 88 and 95 then (0.333333 * price_in_usd)
+                                when datediff(day, start_time, expected_end_time) between 179 and 185 then (0.1666666 * price_in_usd)
+                                when datediff(day, start_time, expected_end_time) between 363 and 375 then (0.08333 * price_in_usd)
+                                else ((28 / (datediff('s', start_time, expected_end_time) / (24 * 3600))) * price_in_usd)
+                            end
+                        /* then handle cases where product_duration can be used */
+                    when product_duration = 'P1D' then (30 * price_in_usd)
+                    when product_duration = 'P3D' then (10 * price_in_usd)
+                    when product_duration = 'P7D' then (4 * price_in_usd)
+                    when product_duration = 'P1W' then (4 * price_in_usd)
+                    when product_duration = 'P2W' then (2 * price_in_usd)
+                    when product_duration = 'P4W' then (1 * price_in_usd)
+                    when product_duration = 'P1M' then (1 * price_in_usd)
+                    when product_duration = 'P2M' then (0.5 * price_in_usd)
+                    when product_duration = 'P3M' then (0.333333 * price_in_usd)
+                    when product_duration = 'P6M' then (0.1666666 * price_in_usd)
+                    when product_duration = 'P12M' then (0.08333 * price_in_usd)
+                    when product_duration = 'P1Y' then (0.08333 * price_in_usd)
+                    else ((28 / (datediff('s', start_time, expected_end_time) / (24 * 3600))) * price_in_usd)
                 end
-                /* then handle cases where product_duration can be used */
-                when product_duration = 'P1D' 
-                    then (30 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P3D' 
-                    then (10 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P7D' 
-                    then (4 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P1W' 
-                    then (4 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P2W' 
-                    then (2 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P4W' 
-                    then (1 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P1M' 
-                    then (1 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P2M' 
-                    then (0.5 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P3M' 
-                    then (0.333333 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P6M' 
-                    then (0.1666666 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P12M' 
-                    then (0.08333 * price_in_usd)::decimal(18,2)
-                when product_duration = 'P1Y' 
-                    then (0.08333 * price_in_usd)::decimal(18,2)
-                else ((28 / (datediff('s', start_time, expected_end_time)::float / (24 * 3600))) * price_in_usd)::decimal(18,2)
-            end
         end as mrr_in_usd,
         takehome_percentage,
 

From 6d56aaaf0b1352e745108dd5ca5c680aa9212bab Mon Sep 17 00:00:00 2001
From: Jurri Gerretsen <62351599+jurrigerretsen@users.noreply.github.com>
Date: Thu, 22 Feb 2024 08:39:16 +0100
Subject: [PATCH 3/4] =?UTF-8?q?=F0=9F=8E=A8=20Rounded=20off=20instead=20of?=
 =?UTF-8?q?=20using=20decimals=20for=20better=20cross=20db=20support?=
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit

---
 .../revenuecat_subscription_transactions.sql  | 46 +++++++++----------
 1 file changed, 23 insertions(+), 23 deletions(-)

diff --git a/models/core/revenuecat_subscription_transactions.sql b/models/core/revenuecat_subscription_transactions.sql
index 25f55c3..f45d551 100644
--- a/models/core/revenuecat_subscription_transactions.sql
+++ b/models/core/revenuecat_subscription_transactions.sql
@@ -57,31 +57,31 @@ renamed as (
                     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 (30 * price_in_usd)
-                                when datediff(day, start_time, expected_end_time) = 3 then (10 * price_in_usd)
-                                when datediff(day, start_time, expected_end_time) between 6 and 8 then (4 * price_in_usd)
-                                when datediff(day, start_time, expected_end_time) between 12 and 16 then (2 * price_in_usd)
-                                when datediff(day, start_time, expected_end_time) between 27 and 33 then (1 * price_in_usd)
-                                when datediff(day, start_time, expected_end_time) between 58 and 62 then (0.5 * price_in_usd)
-                                when datediff(day, start_time, expected_end_time) between 88 and 95 then (0.333333 * price_in_usd)
-                                when datediff(day, start_time, expected_end_time) between 179 and 185 then (0.1666666 * price_in_usd)
-                                when datediff(day, start_time, expected_end_time) between 363 and 375 then (0.08333 * price_in_usd)
-                                else ((28 / (datediff('s', start_time, expected_end_time) / (24 * 3600))) * price_in_usd)
+                                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 (30 * price_in_usd)
-                    when product_duration = 'P3D' then (10 * price_in_usd)
-                    when product_duration = 'P7D' then (4 * price_in_usd)
-                    when product_duration = 'P1W' then (4 * price_in_usd)
-                    when product_duration = 'P2W' then (2 * price_in_usd)
-                    when product_duration = 'P4W' then (1 * price_in_usd)
-                    when product_duration = 'P1M' then (1 * price_in_usd)
-                    when product_duration = 'P2M' then (0.5 * price_in_usd)
-                    when product_duration = 'P3M' then (0.333333 * price_in_usd)
-                    when product_duration = 'P6M' then (0.1666666 * price_in_usd)
-                    when product_duration = 'P12M' then (0.08333 * price_in_usd)
-                    when product_duration = 'P1Y' then (0.08333 * price_in_usd)
-                    else ((28 / (datediff('s', start_time, expected_end_time) / (24 * 3600))) * price_in_usd)
+                    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,

From 002960cbd955038c5c3edc60886444fd7bd92141 Mon Sep 17 00:00:00 2001
From: Jurri Gerretsen <62351599+jurrigerretsen@users.noreply.github.com>
Date: Thu, 22 Feb 2024 08:53:51 +0100
Subject: [PATCH 4/4] =?UTF-8?q?=F0=9F=8E=A8=20Remove=20sysdate=20for=20mor?=
 =?UTF-8?q?e=20conventional=20convert=5Ftimezone?=
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit

---
 models/analysis/revenuecat_monthly_recurring_revenue.sql | 2 +-
 1 file changed, 1 insertion(+), 1 deletion(-)

diff --git a/models/analysis/revenuecat_monthly_recurring_revenue.sql b/models/analysis/revenuecat_monthly_recurring_revenue.sql
index bfe9f3e..39c8452 100644
--- a/models/analysis/revenuecat_monthly_recurring_revenue.sql
+++ b/models/analysis/revenuecat_monthly_recurring_revenue.sql
@@ -52,7 +52,7 @@ final as (
         transaction_monthly_revenue
         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', SYSDATE()::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
+                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