Skip to content
This repository has been archived by the owner on Mar 22, 2024. It is now read-only.

New SDE Sample Queries #691

Open
wants to merge 21 commits into
base: main
Choose a base branch
from
Open

New SDE Sample Queries #691

wants to merge 21 commits into from

Conversation

dpannasch
Copy link
Collaborator

@dpannasch dpannasch commented Feb 6, 2024

Motivation / Description

Two general changes in here:

  1. New sample queries for Active Subs Mvmt, MRR Mvmt, and MRR have been added
  2. And I did another round of cleanup on the existing queries for consistency

Background is in Slack here.

TL;DR Customer is looking to reproduce Charts and is expecting us to have QA'ed queries to do so with so they can rely on them. I've done that myself for all of these queries and was able to get numbers that match up perfectly for individual data points, and are very close for aggregations (can reasonably be chalked up to freshness differences between sources).

The only exception to that is my MRR query is slightly off right now after my last round of reformatting, so I'm going to QA that further before setting this as ready for review.

UPDATE: MRR reconciles perfectly for days > 1 day ago, so I'm very confident this is a data freshness problem now.

Changes introduced

Linear ticket (if any)

Additional comments

@dpannasch dpannasch marked this pull request as ready for review February 6, 2024 21:51
Copy link
Collaborator Author

Choose a reason for hiding this comment

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

@toppare Here's the most complex new query that I'd love your feedback on (the others are simplifications of this same base query)

Copy link
Collaborator Author

Choose a reason for hiding this comment

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

You can ignore the lines subtracted / added notes from Github. They were just indentation changes for consistency that I made in a later commit, the whole query is new as of this PR.

[revenuecat_data_table]
WHERE (start_time BETWEEN [targeted_start_date] and [targeted_end_date]
OR effective_end_time BETWEEN [targeted_start_date] and [targeted_end_date])
AND is_trial_period = 'false'
Copy link

Choose a reason for hiding this comment

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

this is an important filter, better to add some comments here

Copy link
Collaborator Author

Choose a reason for hiding this comment

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

Which one? AND is_trial_period = 'false'? If so I added this: /* Exclude trials, which do not contribute to MRR */

But I feel like you may be referring to a different filter that wasn't explicit enough

CASE
WHEN expires_date IS NOT NULL
AND is_trial_period = 'false'
AND (is_trial_conversion = 'false' AND renewal_number = 1)
Copy link

Choose a reason for hiding this comment

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

I didn't understand why we need is_trial_conversion = 'false' isn't it enough to put renewal_number=1 ?

Copy link
Collaborator Author

Choose a reason for hiding this comment

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

Good catch -- this query returns 0:

SELECT COUNT(*) FROM transactions
WHERE renewal_number = 1
AND is_trial_conversion = true
AND is_sandbox <> true

I'll update it (there are many small changes like this that we should be able to bring back into the real Actives cube to make that simpler as well)

Copy link

Choose a reason for hiding this comment

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

I think we can simplify the code like below:

case when is_trial_conversion=true or renewal_number = 1 then 'new_mrr'
else 'renewal_mrr'

and we can be confident that all cases are covered

@RCGitBot
Copy link
Contributor

RCGitBot commented Feb 9, 2024

Previews

temp/scheduled-data-exports.md

See contents

👍

Scheduled data exports are available to all users signed up after September '23, the legacy Grow and Pro plans, and Enterprise plans. If you're on a legacy Free or Starter plan and want to access this integration, migrate to our new pricing via your billing settings.

RevenueCat can automatically send data deliveries of all of your apps' transaction data to various cloud storage providers. These are in the form of gzip compressed .csv files delivered daily.

Setup Instructions

  • Amazon S3 Setup
  • Google Cloud Storage Setup

📘

Customers on our Enterprise plan have the option to receive data exports more frequently than once per day when receiving new and updated transactions only. Contact your Customer Success Manager with questions, or visit our Pricing Page to learn more.

Version Change Log

Transaction Format

Applicable to the latest version

📘

All dates and times are provided in UTC.

[block:parameters]
{
"data": {
"h-0": "Header",
"h-1": "Description",
"h-2": "Type",
"h-3": "Example value",
"h-4": "Can be null",
"0-0": "rc_original_app_user_id",
"0-1": "Can be used as a unique user identifier to find all of a user's transactions.",
"0-2": "string",
"0-3": "$RCAnonymousID:87c6049c58069238dce29853916d624c",
"0-4": "",
"1-0": "rc_last_seen_app_user_id_alias",
"1-1": "Can be used together with rc_original_app_user_id to match transactions with user identifiers in your systems.",
"1-2": "string",
"1-3": "$RCAnonymousID:87c6049c58069238dce29853916d624c",
"1-4": "",
"2-0": "country",
"2-1": "Store country of a transaction when known, or an IP-based estimate of a subscriber's country when not known.",
"2-2": "string",
"2-3": "GB",
"2-4": "✅",
"3-0": "country_source",
"3-1": "from_sdk when the store country of a transaction is known, or estimated when country is sourced from an IP-based estimate.",
"3-2": "string",
"3-3": "from_sdk",
"3-4": "✅",
"4-0": "product_identifier",
"4-1": "The product identifier that was purchased.",
"4-2": "string",
"4-3": "rc_subscription_monthly",
"4-4": "",
"5-0": "product_display_name",
"5-1": "The display name of the product identifier if one has been set",
"5-2": "string",
"5-3": "Monthly $9.99",
"5-4": "✅",
"6-0": "product_duration",
"6-1": "The standard duration of the product if one is known by RevenueCat. May be null if RevenueCat does not know the authoritative duration. \n \nproduct_duration does not represent the trial or introductory period length of a transaction, it only represents the standard duration of the product that's been subscribed to.",
"6-2": "string",
"6-3": "P1M",
"6-4": "✅",
"7-0": "start_time",
"7-1": "Purchase time of transaction.",
"7-2": "datetime",
"7-3": "2023-01-01 08:27:06",
"7-4": "",
"8-0": "end_time",
"8-1": "Expected expiration time of subscription. Null when is_auto_renewable = false \nFor Google Play, end_time can be before start_time to indicate an invalid transaction (e.g. billing issue).",
"8-2": "datetime",
"8-3": "2023-02-01 08:27:06",
"8-4": "✅",
"9-0": "grace_period_end_time",
"9-1": "Expiration time of a grace period (if applicable) for a subscription. Will remain set while a subscription is in its grace period, or if it exited its grace period without renewing. Null when a subscription is not in a grace period or expiration was not due to a grace period.",
"9-2": "datetime",
"9-3": "2023-02-17 08:27:06",
"9-4": "✅",
"10-0": "effective_end_time",
"10-1": "Single reference point of a subscriber’s expiration and entitlement revocation; inclusive of each store’s logic for refunds, grace periods, etc.",
"10-2": "datetime",
"10-3": "2023-02-17 08:27:06",
"10-4": "✅",
"11-0": "store",
"11-1": "The source of the transaction. Can be app_store, play_store, stripe, or promotional.",
"11-2": "string",
"11-3": "play_store",
"11-4": "",
"12-0": "is_auto_renewable",
"12-1": "true for auto-renewable subscriptions, false otherwise.",
"12-2": "boolean",
"12-3": "true",
"12-4": "",
"13-0": "is_trial_period",
"13-1": "true if the transaction was a trial.",
"13-2": "boolean",
"13-3": "false",
"13-4": "",
"14-0": "is_in_intro_offer_period",
"14-1": "true if the transaction is in an introductory offer period.",
"14-2": "boolean",
"14-3": "false",
"14-4": "",
"15-0": "is_sandbox",
"15-1": "true for transactions made in a sandbox environment.",
"15-2": "boolean",
"15-3": "false",
"15-4": "",
"16-0": "price_in_usd",
"16-1": "The revenue (converted to USD) generated from the transaction after accounting for full and partial refunds. Can be null if product prices haven't been collected from the user's device. ",
"16-2": "float",
"16-3": "0",
"16-4": "✅",
"17-0": "purchase_price_in_usd",
"17-1": "The gross revenue (converted to USD) generated from the transaction. Remains set for refunded transactions. Can be null if product prices haven't been collected from the user's device.",
"17-2": "float",
"17-3": "9.99",
"17-4": "✅",
"18-0": "takehome_percentage",
"18-1": "[DEPRECATED] The estimated percentage of the transaction price that will be paid out to developers after commissions, but before VAT and DST taxes are taken into account. (will be either 0.7 or 0.85) \n \nWe recommend using tax_percentage and commission_percentage to calculate proceeds instead. Learn more here.",
"18-2": "float",
"18-3": "0.7",
"18-4": "",
"19-0": "tax_percentage",
"19-1": "The portion of a transaction’s price that will be deducted by the store for taxes. VAT & Digital Services Taxes may be withheld by stores depending on the store and country. To learn more about how RevenueCat estimates taxes, click here.",
"19-2": "float",
"19-3": "0.1442",
"19-4": "",
"20-0": "commission_percentage",
"20-1": "The portion of a transaction’s price that will be detected by the store for commission. In stores where taxes are deducted before commission, this value will not equal the published commission from a store, because that commission is calculated on the post-tax revenue.",
"20-2": "float",
"20-3": "0.15",
"20-4": "",
"21-0": "store_transaction_id",
"21-1": "orderId or transaction_identifier. ​Can be used as unique id.",
"21-2": "string",
"21-3": "123456789012345",
"21-4": "",
"22-0": "original_store_transaction_id",
"22-1": "orderId of first purchase or original_transaction_id. Can be used to find all related transactions for a single subscription.",
"22-2": "string",
"22-3": "011223344556677",
"22-4": "",
"23-0": "refunded_at",
"23-1": "When a refund was detected, null if none was detected. Is not set in the case of upgraded transactions for which the App Store issues a partial refund.",
"23-2": "datetime",
"23-3": "2023-02-20 05:47:55",
"23-4": "✅",
"24-0": "unsubscribe_detected_at",
"24-1": "When we detected an unsubscribe (opt-out of auto renew).",
"24-2": "datetime",
"24-3": "2023-02-16 14:17:10",
"24-4": "✅",
"25-0": "billing_issues_detected_at",
"25-1": "When we detected billing issues, null if none was detected.",
"25-2": "datetime",
"25-3": "2023-02-01 08:27:15",
"25-4": "✅",
"26-0": "purchased_currency",
"26-1": "The currency that was used for the transaction.",
"26-2": "string",
"26-3": "GBP",
"26-4": "✅",
"27-0": "price_in_purchased_currency",
"27-1": "The revenue (in the purchased currency) generated from the transaction after accounting for full and partial refunds. Can be null if product prices haven't been collected from the user's device.",
"27-2": "float",
"27-3": "0",
"27-4": "✅",
"28-0": "purchase_price_in_purchased_currency",
"28-1": "The gross revenue (in the purchased currency) generated from the transaction. Remains set for refunded transactions. Can be null if product prices haven't been collected from the user's device.",
"28-2": "float",
"28-3": "3.99",
"28-4": "✅",
"29-0": "entitlement_identifiers",
"29-1": "An array of entitlements that the transaction unlocked or null if it didn't unlock any entitlements.",
"29-2": "string array",
"29-3": "\"[\"\"membership\"\", \"\"full_access\"\"]\"",
"29-4": "✅",
"30-0": "renewal_number",
"30-1": "Always starts at 1. Trial conversions are counted as renewals. is_trial_conversion is used to signify whether a transaction was a trial conversion.",
"30-2": "integer",
"30-3": "2",
"30-4": "",
"31-0": "is_trial_conversion",
"31-1": "If true, this transaction is a trial conversion.",
"31-2": "boolean",
"31-3": "true",
"31-4": "",
"32-0": "presented_offering",
"32-1": "The offering presented to users.",
"32-2": "string",
"32-3": "Default Offering",
"32-4": "✅",
"33-0": "ownership_type",
"33-1": "Will be PURCHASED when a recorded transaction results from the subscriber’s direct purchase of it, or FAMILY_SHARED when a recorded transaction results from the subscriber having received it through Family Sharing. \n \nNOTE: The FAMILY_SHARED designation is only supported on App Store transactions.",
"33-2": "string",
"33-3": "PURCHASED",
"33-4": "✅",
"34-0": "reserved_subscriber_attributes",
"34-1": "The reserved subscriber attributes set for the subscriber. Keys begin with $.",
"34-2": "string JSON",
"34-3": "\"{\"\"$ip\"\": {\"\"value\"\": \"\"203.78.120.117\"\", \"\"updated_at_ms\"\": 1672549200}, \"\"$gpsAdId\"\": {\"\"value\"\": \"\"80480bdc-06e0-11ee-be56-0242ac120002\"\", \"\"updated_at_ms\"\": 1672549200}, \"\"$androidId\"\": {\"\"value\"\": \"\"12345a9876b4c123\"\", \"\"updated_at_ms\"\": 1673097132390}}\"",
"34-4": "✅",
"35-0": "custom_subscriber_attributes",
"35-1": "The custom attributes set for the subscriber.",
"35-2": "string JSON",
"35-3": "\"{\"\"feature_setting\"\": {\"\"value\"\": \"\"1\"\", \"\"updated_at_ms\"\": 1672549200}, \"\"survey_response\"\": {\"\"value\"\": \"\"2\"\", \"\"updated_at_ms\"\": 1599112814785}}\"",
"35-4": "✅",
"36-0": "platform",
"36-1": "Last seen platform of the subscriber.",
"36-2": "string",
"36-3": "android",
"36-4": "✅",
"37-0": "experiment_id",
"37-1": "The unique ID of the Experiment that the subscriber is or was enrolled in. Will be null if the subscriber has not been enrolled in an experiment. \n \nLearn more about Experiments here.",
"37-2": "string",
"37-3": "prexp3a8a234abc",
"37-4": "✅",
"38-0": "experiment_variant",
"38-1": "The value of the Experiment variant that the subscriber is or was enrolled in. a represents the Control, and b represents the Treatment. Will be null if the subscriber has not been enrolled in an experiment. \n \nLearn more about Experiments here.",
"38-2": "string",
"38-3": "a",
"38-4": "✅",
"39-0": "updated_at",
"39-1": "The last time an attribute of the transaction was modified.",
"39-2": "datetime",
"39-3": "2023-02-20 05:47:55",
"39-4": "",
"40-0": "offer\",
"40-1": "The offer that was used for a transaction (if applicable).",
"40-2": "string",
"40-3": "black_friday_discount",
"40-4": "✅",
"41-0": "offer_type\
",
"41-1": "The type of offer that was used for a transaction (if applicable).",
"41-2": "string",
"41-3": "offer_code",
"41-4": "✅",
"42-0": "first_seen_time\",
"42-1": "The time the customer was first seen by RevenueCat.",
"42-2": "datetime",
"42-3": "2023-01-01 03:00:00",
"42-4": "",
"43-0": "auto_resume_time\
",
"43-1": "The time when a Play Store subscription would resume after being paused.",
"43-2": "datetime",
"43-3": "2023-03-20 03:00:00",
"43-4": "✅"
},
"cols": 5,
"rows": 44,
"align": [
"left",
"left",
"left",
"left",
"left"
]
}
[/block]

*Available only on our most recent export version

A note on transaction data

All transaction data is based on the store receipts that RevenueCat has received. Receipts often have inconsistencies and quirks which may need to be considered. For example:

  • The expiration date of a purchase can be before the purchase date. This is Google's way of invalidating a transaction, for example when Google is unable to bill a user some time after a subscription renews. This doesn’t occur on iOS.
  • If you migrated to RevenueCat, Google subscriptions that were expired for more then 60 days before being migrated will not have transaction histories in export files.
  • Apple and Google do not always provide the transaction price directly, so we rely on historical data & store APIs. This may result in inaccuracies if receipts were imported, or if a product price was increased before your App Store Connect API Key was added.
  • Renewal numbers start at 1, even for trials. Trial conversions increase the renewal number.
  • Data is pulled from a snapshot of the current receipt state, this means that the same transaction can be different from one delivery to another if something changed (e.g. due to a refund or billing issue). You should recompute metrics for past time periods periodically to take these changes into account. You can use the updated_at field to detect if a transaction may have changed since a prior export.

We try to normalize or at least annotate these quirks as much as possible, but by and large we consider receipts as the sources of truth, so any inconsistencies in the transaction data can always be traced back to the receipt.

Updating to the latest version

If you're on an older version of our exports, updating is easy:

  1. Open app.revenuecat.com
  2. Navigate to your Project in Project Settings
  3. Click on your Scheduled Data Exports integration in the “Integrations” side panel
  4. Click UPDATE TEMPLATE
  5. After confirming that your data pipeline is configured to ingest the described changes, click UPDATE in the confirmation modal to complete the update.

[block:image]
{
"images": [
{
"image": [
"https://files.readme.io/c12c793-v2.png",
"",
""
],
"align": "center"
}
]
}
[/block]

🚧 Data Format Changes

Please note that Version 4 and all subsequent templates include data format changes which must be incorporated into your data pipeline before updating. Learn more here.

Sample queries for RevenueCat measures

You can use the following sample queries (written in Postgresql) as starting points for reproducing common RevenueCat measures.

-- Active Subscriptions as of a specified date

SELECT
  COUNT(*)
FROM
  [revenuecat_data_table]
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'

-- The RevenueCat Active Subscriptions chart excludes trials,
-- promotional transactions, and transactions resulting from family sharing
-- since they do not reflect auto-renewing future payments.
-- Active Subscriptions Movement within a specified date range

WITH

filtered_subscriptipon_transactions AS (
    SELECT
        *
    FROM [revenuecat_data_table]
    /* Filter down to the date range that you want to measure MRR Movement for */
    WHERE (start_time BETWEEN [targeted_start_date] and [targeted_end_date] 
        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 ownership_type != 'FAMILY_SHARED'
        AND store != 'promotional'
        AND is_sandbox != 'true'),

actives AS (
  SELECT
    DATE(start_time) AS date,
    COUNT(
        CASE 
            WHEN renewal_number = 1
                OR is_trial_conversion = 'true'
            THEN 1 
            ELSE NULL 
        END) AS num_new_actives,
    COUNT(
        CASE 
            WHEN renewal_number > 1
                AND is_trial_conversion = 'false'  
            THEN 1 
            ELSE NULL 
        END
    ) AS num_renewals
    
  FROM filtered_subscriptipon_transactions
  GROUP BY 1),
  
expirations AS (
  SELECT
    DATE(effective_end_time) AS date,
    COUNT(*) AS num_expirations
  FROM filtered_subscriptipon_transactions
  GROUP BY 1)

SELECT
    COALESCE(a.date, e.date) AS date,
    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,
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]
-- MRR as of a specified date

SELECT
    SUM(
        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 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)
                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)
            END
        END 
    ) AS active_mrr
FROM [revenuecat_data_table] 

/* Filter down to the date range that you want to measure MRR Movement for */
WHERE date(effective_end_time) > '2024-02-06'
  AND date(start_time) <= '2024-02-06'
  /* Exclude trials, which do not contribute to MRR */
  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'
-- MRR Movement for a specified date range

WITH

filtered_subscriptipon_transactions AS (
    SELECT
        *,
        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 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)
                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)
            END
        END AS transaction_mrr
    FROM [revenuecat_data_table]
    /* Filter down to the date range that you want to measure MRR Movement for */
    WHERE (start_time BETWEEN [targeted_start_date] and [targeted_end_date] 
        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 ownership_type != 'FAMILY_SHARED'
        AND store != 'promotional'
        AND is_sandbox != 'true'),

actives AS (
  SELECT
    DATE(start_time) AS date,
    SUM(
        CASE
            WHEN renewal_number = 1
                OR is_trial_conversion = 'true' 
            THEN transaction_mrr
            ELSE null
        END
    ) AS new_mrr,
    
    SUM(
        CASE
            WHEN renewal_number > 1 
                AND is_trial_conversion = 'false' 
            THEN transaction_mrr
            ELSE null
        END
    ) AS renewal_mrr
    
  FROM filtered_subscriptipon_transactions
  GROUP BY 1),
  
expirations AS (
  SELECT
    DATE(effective_end_time) AS date,
    SUM(transaction_mrr) AS expired_mrr
  FROM filtered_subscriptipon_transactions
  GROUP BY 1)

SELECT
    COALESCE(a.date, e.date) AS date,
    COALESCE(a.new_mrr, 0) AS new_mrr,
    COALESCE(a.renewal_mrr, 0) as renewal_mrr,
    COALESCE(e.expired_mrr, 0) as expired_mrr,
    expired_mrr - renewal_mrr as churned_mrr
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]
-- Active Trials as of your [targeted_date]

SELECT
  COUNT(*)
FROM
  [revenuecat_data_table]
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'

-- The RevenueCat Active Trials chart excludes
-- promotional transactions and transactions resulting from family sharing
-- since they do not reflect auto-renewing future payments.
-- Revenue generated on a specified date

SELECT
  SUM(purchase_price_in_usd) as gross_revenue,
  SUM(price_in_usd) as revenue_net_of_refunds, /* "Total Revenue" in the Revenue Chart */
  SUM(price_in_usd * (1 - tax_percentage - commission_percentage)) as proceeds
FROM
  [revenuecat_data_table]
WHERE date(start_time) = [targeted_date]
  AND is_trial_period = 'false'
  AND ownership_type != 'FAMILY_SHARED'
  AND store != 'promotional'
  AND is_sandbox != 'true'

-- Transactions which have been refunded can be identified through the refunded_at field.

Sample queries for customized measures

Scheduled Data Exports are a powerful way to add your own customizations on top of the core measures provided by RevenueCat. Check out the following sample queries (written in Postgresql) for some ideas.

-- How many Active Subscriptions do I have with a given custom attribute value?
  
SELECT
  COUNT(*)
FROM
  [revenuecat_data_table] rc
  
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'
  AND json_extract_path_text(custom_subscriber_attributes, '[custom_attribute_key].value') = [custom_attribute_value]
-- What is my split of Active Subs by auto renew status?
  
SELECT
  CASE 
    WHEN unsubscribe_detected_at IS NOT NULL THEN 'Set to cancel' 
    ELSE 'Set to renew' 
    END) as auto_renew_status,
  COUNT(*) as active_subscriptions
FROM
  [revenuecat_data_table]
  
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'
  GROUP BY 1
-- What is my weekly revenue, where Monday is set as the start day of the week?

SELECT
  date_trunc('week', start_time) as week,
  SUM(price_in_usd) as total_revenue
FROM
  [revenuecat_data_table]
WHERE date(start_time) BETWEEN [targeted_period_start_date] AND [targeted_period_end_date]
  AND is_trial_period = 'false'
  AND ownership_type != 'FAMILY_SHARED'
  AND store != 'promotional'
  AND is_sandbox != 'true'
GROUP BY week
-- What is my Realized LTV of each monthly subscription cohort, segmented by whether they were offered a trial?
  
WITH 
(SELECT
  MIN(start_time) as subscription_start_time,
  original_store_transaction_id,
  MAX(is_trial_period) as had_a_trial,
  SUM(price_in_usd) as realized_ltv
FROM
  [revenuecat_data_table]
WHERE date(start_time) > [targeted_period_start_date]
  AND ownership_type != 'FAMILY_SHARED'
  AND store != 'promotional'
  AND is_sandbox != 'true'
  GROUP BY original_store_transaction_id) as subscriptions
  
SELECT
  to_char(first_start_time, 'YYYY-MM') as subscription_start_month,
  had_a_trial,
  COUNT() as subscriptions,
  SUM(realized_ltv) as realized_ltv,
  SUM(realized_ltv) / COUNT() as realized_ltv_per_subscription
FROM
  subscriptions
-- What portion of my Active Trials are in a grace period?
  
SELECT
  CASE
    WHEN grace_period_end_time IS NOT NULL THEN 'in_grace_period'
    ELSE 'in_trial_period'
    END as period_type,
  COUNT(*) as active_trials
FROM
  [revenuecat_data_table]
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'
GROUP BY period_type
-- What is my Realized LTV per Paying Customer cohorted by First Purchase Date?
  
WITH filtered_transactions AS
  (SELECT *
  FROM [revenuecat_data_table]
  WHERE is_trial_period = 'false'
    AND ownership_type != 'FAMILY_SHARED'
    AND store != 'promotional'
    AND is_sandbox != 'true'
    AND was_refunded = 'false'
    AND price > 0),

first_purchase_dates AS
  (SELECT
    rc_original_app_user_id,
    MIN(start_time) as first_purchase_date
  FROM filtered_transactions
  GROUP BY 1)

SELECT

  DATE(fpd.first_purchase_date) AS first_purchase_date,
  COUNT(DISTINCT rc_original_app_user_id) AS paying_customers,
  SUM(CASE WHEN DATEADD(day, 7, first_purchase_date) > start_time 
    THEN price_in_usd ELSE 0 END)::DECIMAL(18,2) AS total_ltv_7_days,
  SUM(CASE WHEN DATEADD(day, 30, first_purchase_date) > start_time 
    THEN price_in_usd ELSE 0 END)::DECIMAL(18,2) AS total_ltv_30_days,
  SUM(CASE WHEN DATEADD(month, 6, first_purchase_date) > start_time 
    THEN price_in_usd ELSE 0 END)::DECIMAL(18,2) AS total_ltv_6_months,
  SUM(CASE WHEN DATEADD(month, 12, first_purchase_date) > start_time 
    THEN price_in_usd ELSE 0 END)::DECIMAL(18,2) AS total_ltv_12_months,
  SUM(CASE WHEN DATEADD(month, 24, first_purchase_date) > start_time 
    THEN price_in_usd ELSE 0 END)::DECIMAL(18,2) AS total_ltv_24_months,
  SUM(price_in_usd)::DECIMAL(18,2) AS total_ltv_unbounded,

  (SUM(CASE WHEN DATEADD(day, 7, first_purchase_date) > start_time 
    THEN price_in_usd ELSE 0 END)/COUNT(DISTINCT rc_original_app_user_id))::DECIMAL(18,2) AS avg_ltv_7_days,
  (SUM(CASE WHEN DATEADD(day, 30, first_purchase_date) > start_time 
    THEN price_in_usd ELSE 0 END)/COUNT(DISTINCT rc_original_app_user_id))::DECIMAL(18,2) AS avg_ltv_30_days,
  (SUM(CASE WHEN DATEADD(month, 6, first_purchase_date) > start_time 
    THEN price_in_usd ELSE 0 END)/COUNT(DISTINCT rc_original_app_user_id))::DECIMAL(18,2) AS avg_ltv_6_months,
  (SUM(CASE WHEN DATEADD(month, 12, first_purchase_date) > start_time 
    THEN price_in_usd ELSE 0 END)/COUNT(DISTINCT rc_original_app_user_id))::DECIMAL(18,2) AS avg_ltv_12_months,
  (SUM(CASE WHEN DATEADD(month, 23, first_purchase_date) > start_time 
    THEN price_in_usd ELSE 0 END)/COUNT(DISTINCT rc_original_app_user_id))::DECIMAL(18,2) AS avg_ltv_24_months,
  (SUM(price_in_usd)/COUNT(DISTINCT rc_original_app_user_id))::DECIMAL(18,2) AS avg_ltv_unbounded

FROM filtered_transactions ft
LEFT JOIN first_purchase_dates fpd 
  ON fpd.rc_original_app_user_id = ft.rc_original_app_user_id
GROUP BY 1

temp/unity.md

See contents

What is RevenueCat?

RevenueCat provides a backend and a wrapper around StoreKit and Google Play Billing to make implementing in-app purchases and subscriptions easy. With our SDK, you can build and manage your app business on any platform without having to maintain IAP infrastructure. You can read more about how RevenueCat fits into your app or you can sign up free to start building.

Installation

We provide 2 ways to install our SDK: via Unity Package Manager (UPM) in the OpenUPM registry, or as a .unitypackage.

Option 1 (recommended): Install using OpenUPM

  1. First you need to import the EDM4U plugin into your project if you haven't already. This plugin will add all the Android and iOS dependencies automatically when building your project. To do this, you can:
    • Download the external-dependency-manager-latest.unitypackage file from the root of the EDM4U repo.
    • Import the downloaded unitypackage to your project.
  2. Then, you can add the OpenUPM scoped registry. To do this, go to your project's settings -> Package Manager, and add a new scoped registry with URL https://package.openupm.com and scopes: com.openupm and com.revenuecat.purchases-unity. It should look like this:
  3. Then, go to the Package Manager and from "My Registries", select the RevenueCat package and click on Install.

[block:callout]
{
"type": "info",
"title": "Using OpenUPM-CLI",
"body": "If you prefer, you can also use OpenUPM-CLI to add the scoped registry and the package through the command line. To do that, install the OpenUPM-CLI if you haven't already, then run openupm add com.revenuecat.purchases-unity. That should be it!"
}
[/block]

[block:callout]
{
"type": "warning",
"title": "If using UnityIAP alongside RevenueCat",
"body": "If you're using UnityIAP, you need to follow special instructions outlined below."
}
[/block]

Configure a Main Gradle Template

Go to Project -> Build Settings -> Player Settings -> Android tab -> Publishing Settings, and check "Custom Base Gradle Template", then close that window.

Screenshot 2024-02-02 at 12 52 35 PM

Go to Assets -> External Dependency Manager -> Android Resolver -> Settings, then check "Patch mainTemplate.gradle"

Screenshot 2024-02-01 at 12 13 50 PM Screenshot 2024-02-02 at 12 52 35 PM

Option 2: Import the Purchases Unity package

Download the latest version of Purchases.unitypackage.

Import the downloaded unitypackage to your Unity project. Make sure the PlayServiceResolver and the ExternalDependencyManager folders are also added. These folders will install the EDM4U plugin, which will add all the Android and iOS dependencies automatically when building your project.
If you're running purchases-unity v3.5.1 or later, also make sure that the RevenueCatPostInstall script is added, since it will set up StoreKit for iOS and prevent issues when uploading builds to App Store Connect in Unity 2020.

[block:callout]
{
"type": "warning",
"title": "ExternalDependencyManager plugin",
"body": "Make sure the ExternalDependencyManager is properly installed. Otherwise our plugin will not be able to compile. If you don't see the option under the Assets menu after restarting the editor, try reinstalling the RevenueCat plugin or manually importing the EDM4U plugin."
}
[/block]

Configure a Main Gradle Template

Go to Project -> Build Settings -> Player Settings -> Android tab -> Publishing Settings, and check "Custom Base Gradle Template", then close that window.

Screenshot 2024-02-02 at 12 52 35 PM

Go to Assets -> External Dependency Manager -> Android Resolver -> Settings, then check "Patch mainTemplate.gradle"

Screenshot 2024-02-01 at 12 13 50 PM Screenshot 2024-02-02 at 12 52 35 PM

Create a GameObject with the Purchases behavior

The Purchases package will include a MonoBehavior called Purchases. This will be your access point to RevenueCat from inside Unity. It should be instantiated once and kept as a singleton. You can use properties to configure your API Key, app user ID (if you have one), and product identifiers you want to fetch.

Link StoreKit (iOS only)

StoreKit should automatically be linked. If you run into any issues, add StoreKit.framework to Linked Frameworks and Libraries in Xcode.

Subclass Purchases.Listener MonoBehavior

The Purchases behavior takes one additional parameter, a GameObject with a Purchases.Listener component. This will be where you handle purchase events, and updated subscriber information from RevenueCat. Here is a simple example:

using System;
using System.Collections.Generic;
using UnityEngine;

public class PurchasesListener : Purchases.UpdatedCustomerInfoListener
{
    public override void CustomerInfoReceived(Purchases.CustomerInfo customerInfo)
    {
        // display new CustomerInfo
    }

    private void Start()
    {
        var purchases = GetComponent<Purchases>();
        purchases.SetDebugLogsEnabled(true);
        purchases.GetOfferings((offerings, error) =>
        {
            if (error != null)
            {
                // show error
            }
            else
            {
                // show offering
            }
        });
    }

    public void BeginPurchase(Purchases.Package package)
    {
        var purchases = GetComponent<Purchases>();
        purchases.PurchasePackage(package, (productIdentifier, customerInfo, userCancelled, error) =>
        {
            if (!userCancelled)
            {
                if (error != null)
                {
                    // show error
                }
                else
                {
                    // show updated Customer Info
                }
            }
            else
            {
                // user cancelled, don't show an error
            }
        });
    }

    void RestoreClicked()
    {
        var purchases = GetComponent<Purchases>();
        purchases.RestorePurchases((customerInfo, error) =>
        {
            if (error != null)
            {
                // show error
            }
            else
            {
                // show updated Customer Info
            }
        });
    }
}

Unity Editor

Running the Purchases SDK is unsupported in the Unity Editor at this time, and may result in NullReferenceException: Object reference not set to an instance of an object errors. Please build and run your app instead.

Proguard rules

If you have enabled Minify in Unity, make sure to add these custom rules to your Assets/Plugins/Android/proguard-user.txt and enable the Custom Proguard File setting in Publishing Settings:

-keep class com.revenuecat.** { *; }

Installation with Unity IAP side by side

[block:callout]
{
"type": "danger",
"body": "Make sure to use version 5.3.0 of our plugin. Due to incompatibilities with the version of BillingClient used by Unity IAP, the latest versions of the plugin won't work alongside Unity IAP until Unity IAP gets updated to BillingClient 6.x.x.",
"title": "Unity IAP doesn't work with version 6 of the purchases plugin"
}
[/block]

Purchases Unity 5.0.0+

RevenueCat's Purchases Unity SDK 5.0.0+

side by side with Unity IAP 4.8.0

This version is only compatible with version 4.8.0 and above of Unity IAP which are the ones that include BillingClient 5.

To install download Purchases.unityPackage and install as normal. Then follow the instructions indicated in the "Troubleshooting "duplicated class" errors"

If using RevenueCat alongside Unity IAP 2.2.0+ or other plugin that includes the Android BillingClient library you will be getting an error when compiling that warns about some BillingClient classes being duplicated.

The easiest way to remove the error would be to tell Gradle to not include the billingclient library that Unity IAP is already including.

In order to do that, make sure you have Custom Main Gradle Template selected in the Android Player Settings... That should create a mainTemplate.gradle inside the Assets/Plugins/Android.

Modify the mainTemplate.gradle to include the following at the end of the dependencies block:

dependencies {
    ...
    
    // ** ADD THIS **
    configurations.all {
        exclude group: 'com.android.billingclient', module: 'billing'
    }
}

Perform a clean up of the resolved dependencies using the Assets/External Dependency Manager/Android Resolver/Delete Resolved Libraries menu. This will cleanup the previously downloaded .aars in Assets/Plugins/Android. Otherwise you could end up with duplicated classes errors.

Also make sure to perform a resolve, so External Dependency Manager adds the right dependencies to the generated build.gradle.

[block:callout]
{
"type": "danger",
"body": "The above instructions instructions will also apply if using other plugin that includes the Android InAppBillingService class, or for some other reason you get an error regarding duplicated classes."
}
[/block]

Troubleshooting "ClassNotFoundException" errors at Runtime in Android

When exporting your project to Android, in the Build Settings window, make sure you uncheck the Symlink Sources checkbox. That will make it so Unity actually uses the correct source files for our SDK.

Installing old versions of the plugin

Purchases Unity 4.2.0+

RevenueCat's Purchases Unity SDK 4.2.0+

side by side with Unity IAP 4.4.0 < 4.8.0

Download Purchases-UnityIAP.unityPackage and install as normal. Skip the rest of the instructions in this page.

Purchases Unity 4.0.0 and 4.1.0

RevenueCat's Purchases Unity SDK 4.1.0+

side by side with Unity IAP 3.3.0 < 4.4.0

Download Purchases-UnityIAP.unityPackage and install as normal. Skip the rest of the instructions in this page.

Next Steps

Sign up for free to subscribe to this conversation on GitHub. Already have an account? Sign in.
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

3 participants