diff --git "a/code_blocks/integrations/code_blocks/\360\237\224\214 Integrations & Events/scheduled-data-exports_10.pgsql" "b/code_blocks/integrations/code_blocks/\360\237\224\214 Integrations & Events/scheduled-data-exports_10.pgsql" index 31deedce1..f37bcd6a7 100644 --- "a/code_blocks/integrations/code_blocks/\360\237\224\214 Integrations & Events/scheduled-data-exports_10.pgsql" +++ "b/code_blocks/integrations/code_blocks/\360\237\224\214 Integrations & Events/scheduled-data-exports_10.pgsql" @@ -2,7 +2,7 @@ WITH -filtered_subscriptipon_transactions AS ( +filtered_subscription_transactions AS ( SELECT * FROM [revenuecat_data_table] @@ -11,7 +11,7 @@ filtered_subscriptipon_transactions AS ( OR effective_end_time BETWEEN [targeted_start_date] and [targeted_end_date]) /* Exclude trials, which do not contribute to MRR */ AND is_trial_period = 'false' - AND DATE_DIFF('s', start_time, end_time)::float > 0 + AND end_time > start_time AND ownership_type != 'FAMILY_SHARED' AND store != 'promotional' AND is_sandbox != 'true'), @@ -35,14 +35,14 @@ actives AS ( END ) AS num_renewals - FROM filtered_subscriptipon_transactions + FROM filtered_subscription_transactions GROUP BY 1), expirations AS ( SELECT DATE(effective_end_time) AS date, COUNT(*) AS num_expirations - FROM filtered_subscriptipon_transactions + FROM filtered_subscription_transactions GROUP BY 1) SELECT @@ -50,7 +50,7 @@ SELECT COALESCE(a.num_new_actives, 0) AS new_actives, COALESCE(a.num_renewals, 0) AS num_renewals, COALESCE(e.num_expirations, 0) AS num_expirations, - num_expirations - num_renewals AS churned_actives, + num_expirations - num_renewals AS churned_actives FROM actives a FULL JOIN expirations e ON a.date = e.date WHERE a.date BETWEEN [targeted_start_date] AND [targeted_end_date] diff --git a/code_blocks/integrations/scheduled-data-exports_1.pgsql b/code_blocks/integrations/scheduled-data-exports_1.pgsql index 5ad5a9199..2335844cc 100644 --- a/code_blocks/integrations/scheduled-data-exports_1.pgsql +++ b/code_blocks/integrations/scheduled-data-exports_1.pgsql @@ -7,7 +7,6 @@ FROM WHERE date(effective_end_time) > [targeted_date] AND date(start_time) <= [targeted_date] AND is_trial_period = 'true' - AND DATE_DIFF('s', start_time, end_time)::float > 0 AND ownership_type != 'FAMILY_SHARED' AND store != 'promotional' AND is_sandbox != 'true' diff --git a/code_blocks/integrations/scheduled-data-exports_10.pgsql b/code_blocks/integrations/scheduled-data-exports_10.pgsql index a95b5d3ab..1472834e6 100644 --- a/code_blocks/integrations/scheduled-data-exports_10.pgsql +++ b/code_blocks/integrations/scheduled-data-exports_10.pgsql @@ -11,7 +11,7 @@ filtered_subscription_transactions AS ( OR effective_end_time BETWEEN [targeted_start_date] and [targeted_end_date]) /* Exclude trials, which do not contribute to MRR */ AND is_trial_period = 'false' - AND DATE_DIFF('s', start_time, end_time)::float > 0 + AND end_time > start_time AND ownership_type != 'FAMILY_SHARED' AND store != 'promotional' AND is_sandbox != 'true'), diff --git a/code_blocks/integrations/scheduled-data-exports_11.pgsql b/code_blocks/integrations/scheduled-data-exports_11.pgsql index 9f00146b3..17f19fcb0 100644 --- a/code_blocks/integrations/scheduled-data-exports_11.pgsql +++ b/code_blocks/integrations/scheduled-data-exports_11.pgsql @@ -10,40 +10,40 @@ filtered_subscription_transactions AS ( /* 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 DATE_DIFF(day, start_time, end_time) BETWEEN 0 AND 1 - THEN (30 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) = 3 - THEN (10 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 6 AND 8 - THEN (4 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 12 AND 16 - THEN (2 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 27 AND 33 - THEN (1 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 58 AND 62 - THEN (0.5 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 88 AND 95 - THEN (0.333333 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 179 AND 185 - THEN (0.1666666 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 363 AND 375 - THEN (0.08333 * price)::DECIMAL(18,2) - ELSE ((28 / (DATE_DIFF('s', start_time, end_time)::float / (24 * 3600))) * price)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 0 AND 1 + THEN (30 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) = 3 + THEN (10 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 6 AND 8 + THEN (4 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 12 AND 16 + THEN (2 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 27 AND 33 + THEN (1 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 58 AND 62 + THEN (0.5 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 88 AND 95 + THEN (0.333333 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 179 AND 185 + THEN (0.1666666 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 363 AND 375 + THEN (0.08333 * price_in_usd)::DECIMAL(18,2) + ELSE ((28 / (EXTRACT(EPOCH FROM (end_time - start_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)::DECIMAL(18,2) - WHEN product_duration = 'P3D' THEN (10 * price)::DECIMAL(18,2) - WHEN product_duration = 'P7D' THEN (4 * price)::DECIMAL(18,2) - WHEN product_duration = 'P1W' THEN (4 * price)::DECIMAL(18,2) - WHEN product_duration = 'P2W' THEN (2 * price)::DECIMAL(18,2) - WHEN product_duration = 'P4W' THEN (1 * price)::DECIMAL(18,2) - WHEN product_duration = 'P1M' THEN (1 * price)::DECIMAL(18,2) - WHEN product_duration = 'P2M' THEN (0.5 * price)::DECIMAL(18,2) - WHEN product_duration = 'P3M' THEN (0.333333 * price)::DECIMAL(18,2) - WHEN product_duration = 'P6M' THEN (0.1666666 * price)::DECIMAL(18,2) - WHEN product_duration = 'P12M' THEN (0.08333 * price)::DECIMAL(18,2) - WHEN product_duration = 'P1Y' THEN (0.08333 * price)::DECIMAL(18,2) - ELSE ((28 / (DATE_DIFF('s', start_time, end_time)::float / (24 * 3600))) * price)::DECIMAL(18,2) + 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 / (EXTRACT(EPOCH FROM (end_time - start_time))::float / (24 * 3600))) * price_in_usd)::DECIMAL(18,2) END END AS transaction_mrr FROM [revenuecat_data_table] @@ -52,7 +52,7 @@ filtered_subscription_transactions AS ( OR effective_end_time BETWEEN [targeted_start_date] and [targeted_end_date]) /* Exclude trials, which do not contribute to MRR */ AND is_trial_period = 'false' - AND DATE_DIFF('s', start_time, end_time)::float > 0 + AND EXTRACT(EPOCH FROM (end_time - start_time))::float > 0 AND ownership_type != 'FAMILY_SHARED' AND store != 'promotional' AND is_sandbox != 'true'), @@ -97,4 +97,4 @@ SELECT FROM actives a FULL JOIN expirations e ON a.date = e.date WHERE a.date BETWEEN [targeted_start_date] AND [targeted_end_date] - AND e.date BETWEEN [targeted_start_date] AND [targeted_end_date] + AND e.date BETWEEN [targeted_start_date] AND [targeted_end_date] \ No newline at end of file diff --git a/code_blocks/integrations/scheduled-data-exports_12.pgsql b/code_blocks/integrations/scheduled-data-exports_12.pgsql index 02a3299b8..1b513ef45 100644 --- a/code_blocks/integrations/scheduled-data-exports_12.pgsql +++ b/code_blocks/integrations/scheduled-data-exports_12.pgsql @@ -7,63 +7,63 @@ SELECT /* 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 DATE_DIFF(day, start_time, end_time) BETWEEN 0 AND 1 - THEN (30 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) = 3 - THEN (10 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 6 AND 8 - THEN (4 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 12 AND 16 - THEN (2 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 27 AND 33 - THEN (1 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 58 AND 62 - THEN (0.5 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 88 AND 95 - THEN (0.333333 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 179 AND 185 - THEN (0.1666666 * price)::DECIMAL(18,2) - WHEN DATE_DIFF(day, start_time, end_time) BETWEEN 363 AND 375 - THEN (0.08333 * price)::DECIMAL(18,2) - ELSE ((28 / (DATE_DIFF('s', start_time, end_time)::float / (24 * 3600))) * price)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 0 AND 1 + THEN (30 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) = 3 + THEN (10 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 6 AND 8 + THEN (4 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 12 AND 16 + THEN (2 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 27 AND 33 + THEN (1 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 58 AND 62 + THEN (0.5 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 88 AND 95 + THEN (0.333333 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 179 AND 185 + THEN (0.1666666 * price_in_usd)::DECIMAL(18,2) + WHEN FLOOR(EXTRACT(EPOCH FROM (end_time - start_time)) / (24 * 3600)) BETWEEN 363 AND 375 + THEN (0.08333 * price_in_usd)::DECIMAL(18,2) + ELSE ((28 / (EXTRACT(EPOCH FROM (end_time - start_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)::DECIMAL(18,2) + THEN (30 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P3D' - THEN (10 * price)::DECIMAL(18,2) + THEN (10 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P7D' - THEN (4 * price)::DECIMAL(18,2) + THEN (4 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P1W' - THEN (4 * price)::DECIMAL(18,2) + THEN (4 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P2W' - THEN (2 * price)::DECIMAL(18,2) + THEN (2 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P4W' - THEN (1 * price)::DECIMAL(18,2) + THEN (1 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P1M' - THEN (1 * price)::DECIMAL(18,2) + THEN (1 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P2M' - THEN (0.5 * price)::DECIMAL(18,2) + THEN (0.5 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P3M' - THEN (0.333333 * price)::DECIMAL(18,2) + THEN (0.333333 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P6M' - THEN (0.1666666 * price)::DECIMAL(18,2) + THEN (0.1666666 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P12M' - THEN (0.08333 * price)::DECIMAL(18,2) + THEN (0.08333 * price_in_usd)::DECIMAL(18,2) WHEN product_duration = 'P1Y' - THEN (0.08333 * price)::DECIMAL(18,2) - ELSE ((28 / (DATE_DIFF('s', start_time, end_time)::float / (24 * 3600))) * price)::DECIMAL(18,2) + THEN (0.08333 * price_in_usd)::DECIMAL(18,2) + ELSE ((28 / (EXTRACT(EPOCH FROM (end_time - start_time))::float / (24 * 3600))) * price_in_usd)::DECIMAL(18,2) END END ) AS active_mrr FROM [revenuecat_data_table] /* Filter down to the date range that you want to measure MRR for */ -WHERE date(effective_end_time) > '2024-02-06' - AND date(start_time) <= '2024-02-06' +WHERE date(effective_end_time) > [targeted_date] + AND date(start_time) <= [targeted_date] /* Exclude trials, which do not contribute to MRR */ AND is_trial_period = 'false' - AND DATE_DIFF('s', start_time, end_time)::float > 0 + AND EXTRACT(EPOCH FROM (end_time - start_time))::float > 0 AND ownership_type != 'FAMILY_SHARED' AND store != 'promotional' - AND is_sandbox != 'true' + AND is_sandbox != 'true' \ No newline at end of file diff --git a/code_blocks/integrations/scheduled-data-exports_2.pgsql b/code_blocks/integrations/scheduled-data-exports_2.pgsql index c0e37985b..70cf8e710 100644 --- a/code_blocks/integrations/scheduled-data-exports_2.pgsql +++ b/code_blocks/integrations/scheduled-data-exports_2.pgsql @@ -7,7 +7,6 @@ FROM WHERE date(effective_end_time) > [targeted_date] AND date(start_time) <= [targeted_date] AND is_trial_period = 'false' - AND DATE_DIFF('s', start_time, end_time)::float > 0 AND ownership_type != 'FAMILY_SHARED' AND store != 'promotional' AND is_sandbox != 'true' diff --git a/code_blocks/integrations/scheduled-data-exports_4.pgsql b/code_blocks/integrations/scheduled-data-exports_4.pgsql index 5fc6a942a..be4e8d21d 100644 --- a/code_blocks/integrations/scheduled-data-exports_4.pgsql +++ b/code_blocks/integrations/scheduled-data-exports_4.pgsql @@ -8,7 +8,6 @@ FROM WHERE date(effective_end_time) > [targeted_date] AND date(start_time) <= [targeted_date] AND is_trial_period = 'false' - AND DATE_DIFF('s', start_time, end_time)::float > 0 AND ownership_type != 'FAMILY_SHARED' AND store != 'promotional' AND is_sandbox != 'true' diff --git a/code_blocks/integrations/scheduled-data-exports_7.pgsql b/code_blocks/integrations/scheduled-data-exports_7.pgsql index 6a1a83e10..e9f5588ff 100644 --- a/code_blocks/integrations/scheduled-data-exports_7.pgsql +++ b/code_blocks/integrations/scheduled-data-exports_7.pgsql @@ -11,7 +11,6 @@ FROM WHERE date(effective_end_time) > [targeted_date] AND date(start_time) <= [targeted_date] AND is_trial_period = 'true' - AND DATE_DIFF('s', start_time, effective_end_time)::float > 0 AND ownership_type != 'FAMILY_SHARED' AND store != 'promotional' AND is_sandbox != 'true' diff --git a/code_blocks/integrations/scheduled-data-exports_9.pgsql b/code_blocks/integrations/scheduled-data-exports_9.pgsql index 4ce453215..9723dac06 100644 --- a/code_blocks/integrations/scheduled-data-exports_9.pgsql +++ b/code_blocks/integrations/scheduled-data-exports_9.pgsql @@ -12,7 +12,6 @@ FROM WHERE date(effective_end_time) > [targeted_date] AND date(start_time) <= [targeted_date] AND is_trial_period = 'false' - AND DATE_DIFF('s', start_time, end_time)::float > 0 AND ownership_type != 'FAMILY_SHARED' AND store != 'promotional' AND is_sandbox != 'true'