├── .gitignore ├── Makefile ├── README.md ├── data └── subscription_periods.csv ├── dbt_project.yml ├── docs ├── catalog.json ├── index.html ├── manifest.json └── run_results.json ├── macros └── grant_select_on_schema.sql ├── models ├── customer_churn_month.sql ├── customer_revenue_by_month.sql ├── mrr.md ├── mrr.sql ├── mrr.yml ├── overview.md ├── schema.yml └── utils │ └── util_months.sql └── packages.yml /.gitignore: -------------------------------------------------------------------------------- 1 | 2 | target/ 3 | dbt_modules/ 4 | logs/ -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | do-everything: 2 | dbt compile --target snowflake 3 | dbt seed --target snowflake --full-refresh 4 | dbt run --target snowflake --full-refresh 5 | dbt test --target snowflake 6 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Monthly Recurring Revenue (MRR) playbook. 2 | This dbt project is a worked example to demonstrate how to model subscription 3 | revenue. **Check out the full write-up [here](https://blog.getdbt.com/modeling-subscription-revenue/), 4 | as well as the documentation site for this project [here](https://www.getdbt.com/mrr-playbook/#!/overview).** 5 | 6 | Note that this project is not a package -- it is not intended to be installed in 7 | your own dbt project, but instead provides a good starting point for building 8 | similar data models for your own business. 9 | 10 | The SQL in this project is compatible with Snowflake¹. 11 | 12 | If you want to run this project yourself to play with it (assuming you have 13 | dbt installed): 14 | 1. Clone this repo. 15 | 2. Create a profile named `playbook`, or update the `profile:` key in the 16 | `dbt_project.yml` file to point to an existing profile ([docs](https://docs.getdbt.com/docs/configure-your-profile)). 17 | 3. Run `dbt deps`. 18 | 4. Run `dbt seed`. 19 | 5. Run `dbt run` -- if you are using a warehouse other than Snowflake, you may 20 | find that you have to update some SQL to be compatible with your warehouse. 21 | 6. Run `dbt test`. 22 | 23 | ----- 24 | 1. We decided to _not_ make the SQL multi-warehouse compatible since this project 25 | is intended to be a demonstration, rather than a package. Making this project 26 | multi-warehouse compatible would complicate the SQL. 27 | -------------------------------------------------------------------------------- /data/subscription_periods.csv: -------------------------------------------------------------------------------- 1 | subscription_id,customer_id,start_date,end_date,monthly_amount 2 | 1,1,2018-11-01,2019-02-01,50 3 | 2,1,2019-04-01,2019-06-01,50 4 | 3,1,2019-06-01,2019-08-01,75 5 | 4,2,2017-09-01,2017-11-01,25 6 | 5,3,2017-09-01,2017-10-01,50 7 | 6,4,2017-10-01,2017-11-01,25 8 | 7,5,2018-11-01,2018-12-01,50 9 | 8,5,2018-12-01,2019-03-01,25 10 | 9,5,2019-07-01,2019-08-01,50 11 | 10,5,2019-08-01,2019-09-01,25 12 | 11,5,2019-09-01,2019-10-01,50 13 | 12,5,2019-10-01,2019-12-01,25 14 | 13,5,2019-12-01,2020-01-01,40 15 | 14,6,2018-05-01,2018-06-01,35 16 | 15,6,2018-06-01,2020-01-01,65 17 | 16,7,2018-01-01,2018-02-01,55 18 | 17,7,2018-02-01,2019-12-01,70 19 | 18,8,2019-04-01,2019-05-01,65 20 | 19,8,2019-05-01,2019-12-01,65 21 | 20,9,2018-05-01,2018-06-01,85 22 | 21,9,2018-06-01,2020-01-01,75 23 | 22,10,2018-04-01,2018-05-01,80 24 | 23,10,2018-09-01,2018-10-01,50 25 | 24,10,2018-10-01,2019-04-01,25 26 | 25,10,2019-04-01,2019-05-01,50 27 | 26,10,2019-05-01,2019-06-01,25 28 | 27,10,2019-06-01,2019-11-01,50 29 | 28,10,2019-11-01,2019-12-01,25 30 | 29,10,2019-12-01,2020-01-01,35 31 | 30,11,2018-09-01,2018-10-01,30 32 | 31,11,2018-10-01,2020-01-01,50 33 | 32,12,2018-06-01,2018-07-01,25 34 | 33,12,2018-07-01,2020-01-01,50 35 | 34,13,2019-08-01,2019-09-01,25 36 | 35,13,2019-09-01,2020-01-01,50 37 | 36,14,2019-03-01,2019-04-01,25 38 | 37,14,2019-04-01,2019-05-01,50 39 | 38,14,2019-05-01,2019-06-01,25 40 | 39,14,2019-06-01,2019-07-01,50 41 | 40,14,2019-07-01,2019-08-01,25 42 | 41,14,2019-08-01,2019-09-01,25 43 | 42,14,2019-09-01,2019-10-01,50 44 | 43,14,2019-10-01,2020-01-01,25 45 | 44,15,2019-02-01,2019-03-01,30 46 | 45,15,2019-03-01,2020-01-01,30 47 | 46,16,2019-07-01,2019-08-01,25 48 | 47,16,2019-08-01,2020-01-01,25 49 | 48,17,2018-11-01,2018-12-01,25 50 | 49,17,2018-12-01,2019-05-01,50 51 | 50,17,2019-05-01,2019-06-01,25 52 | 51,17,2019-06-01,2019-09-01,40 53 | 52,17,2019-09-01,2019-10-01,35 54 | 53,17,2019-10-01,2019-11-01,65 55 | 54,17,2019-11-01,2019-12-01,100 56 | 55,17,2019-12-01,2020-01-01,95 57 | 56,18,2018-11-01,2018-12-01,90 58 | 57,18,2018-12-01,2019-12-01,50 59 | 58,19,2019-05-01,2019-06-01,25 60 | 59,19,2019-06-01,2020-01-01,50 61 | 60,20,2019-01-01,2019-02-01,25 62 | 61,20,2019-02-01,2019-12-01,50 63 | 62,21,2018-11-01,2018-12-01,25 64 | 63,21,2018-12-01,2019-12-01,50 65 | 64,22,2018-12-01,2019-01-01,25 66 | 65,22,2019-01-01,2019-08-01,35 67 | 66,23,2019-03-01,2019-04-01,35 68 | 67,23,2019-04-01,2020-01-01,50 69 | 68,24,2019-05-01,2019-06-01,25 70 | 69,24,2019-06-01,2020-01-01,60 71 | 70,25,2019-08-01,2019-09-01,30 72 | 71,25,2019-09-01,2019-10-01,35 73 | 72,25,2019-10-01,2020-01-01,45 74 | 73,26,2019-05-01,2019-06-01,55 75 | 74,26,2019-06-01,2019-08-01,50 76 | 75,27,2019-07-01,2019-08-01,130 77 | 76,27,2019-08-01,2020-01-01,125 78 | 77,28,2019-07-01,2019-08-01,50 79 | 78,28,2019-08-01,2019-12-01,25 80 | 79,29,2019-06-01,2019-07-01,50 81 | 80,29,2019-07-01,2019-12-01,35 82 | 81,30,2019-04-01,2019-05-01,55 83 | 82,30,2019-05-01,2019-12-01,45 84 | 83,31,2019-11-01,2019-12-01,50 85 | 84,31,2019-12-01,2020-01-01,25 86 | 85,32,2019-05-01,2019-06-01,50 87 | 86,32,2019-06-01,2020-01-01,25 88 | 87,33,2019-10-01,2019-11-01,50 89 | 88,33,2019-11-01,2019-12-01,25 90 | 89,34,2019-08-01,2019-09-01,50 91 | 90,34,2019-09-01,2020-01-01,25 92 | 91,35,2019-10-01,2019-11-01,50 93 | 92,35,2019-11-01,2019-12-01,25 94 | 93,36,2019-09-01,2019-10-01,50 95 | 94,36,2019-10-01,2020-01-01,25 96 | 95,37,2019-09-01,2019-10-01,25 97 | 96,37,2019-10-01,2020-01-01,25 98 | 97,38,2019-09-01,2019-10-01,30 99 | 98,38,2019-10-01,2019-12-01,30 100 | 99,39,2019-11-01,2019-12-01,35 101 | 100,40,2019-09-01,2019-10-01,35 102 | 101,40,2019-10-01,2020-01-01,50 103 | 102,41,2019-11-01,2019-12-01,25 104 | 103,41,2019-12-01,2020-01-01,50 105 | 104,42,2019-09-01,2019-10-01,25 106 | 105,42,2019-10-01,2019-12-01,50 107 | 106,43,2019-11-01,2019-12-01,25 108 | 107,44,2019-10-01,2019-11-01,50 109 | 108,44,2019-11-01,2020-01-01,25 110 | 109,45,2019-10-01,2019-11-01,45 111 | 110,45,2019-11-01,2020-01-01,35 112 | 111,46,2019-12-01,2020-01-01,50 113 | 112,47,2019-10-01,2019-11-01,25 114 | 113,47,2019-11-01,2019-12-01,50 115 | 114,48,2019-11-01,2019-12-01,25 116 | 115,49,2019-11-01,2019-12-01,50 117 | 116,50,2019-12-01,2020-01-01,25 118 | 117,51,2020-01-01,2020-02-01,50 119 | 118,52,2019-12-01,2020-01-01,25 120 | 119,53,2020-01-01,2020-02-01,50 121 | 120,54,2020-01-01,2020-02-01,25 122 | 121,55,2020-01-01,2020-02-01,50 123 | -------------------------------------------------------------------------------- /dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: acme 2 | profile: playbook 3 | version: '1.0' 4 | config-version: 2 5 | 6 | require-dbt-version: ">=0.19.0" 7 | 8 | source-paths: ["models"] 9 | analysis-paths: ["analysis"] 10 | test-paths: ["tests"] 11 | data-paths: ["data"] 12 | macro-paths: ["macros"] 13 | 14 | target-path: "target" 15 | clean-targets: 16 | - "target" 17 | - "dbt_modules" 18 | 19 | seeds: 20 | quote_columns: false 21 | -------------------------------------------------------------------------------- /docs/catalog.json: -------------------------------------------------------------------------------- 1 | {"metadata": {"dbt_schema_version": "https://schemas.getdbt.com/dbt/catalog/v1.json", "dbt_version": "0.19.0", "generated_at": "2021-03-04T18:15:22.671715Z", "invocation_id": "f5a37ed7-b84a-4b6d-999d-2203e09421d7", "env": {}}, "nodes": {"model.acme.customer_revenue_by_month": {"metadata": {"type": "VIEW", "database": "ANALYTICS", "schema": "DBT_CLAIRE", "name": "CUSTOMER_REVENUE_BY_MONTH", "comment": null, "owner": "TRANSFORMER"}, "columns": {"DATE_MONTH": {"type": "TIMESTAMP_NTZ", "comment": null, "index": 1, "name": "DATE_MONTH"}, "CUSTOMER_ID": {"type": "NUMBER", "comment": null, "index": 2, "name": "CUSTOMER_ID"}, "MRR": {"type": "NUMBER", "comment": null, "index": 3, "name": "MRR"}, "IS_ACTIVE": {"type": "BOOLEAN", "comment": null, "index": 4, "name": "IS_ACTIVE"}, "FIRST_ACTIVE_MONTH": {"type": "TIMESTAMP_NTZ", "comment": null, "index": 5, "name": "FIRST_ACTIVE_MONTH"}, "LAST_ACTIVE_MONTH": {"type": "TIMESTAMP_NTZ", "comment": null, "index": 6, "name": "LAST_ACTIVE_MONTH"}, "IS_FIRST_MONTH": {"type": "BOOLEAN", "comment": null, "index": 7, "name": "IS_FIRST_MONTH"}, "IS_LAST_MONTH": {"type": "BOOLEAN", "comment": null, "index": 8, "name": "IS_LAST_MONTH"}}, "stats": {"has_stats": {"id": "has_stats", "label": "Has Stats?", "value": false, "description": "Indicates whether there are statistics for this table", "include": false}}, "unique_id": "model.acme.customer_revenue_by_month"}, "model.acme.mrr": {"metadata": {"type": "VIEW", "database": "ANALYTICS", "schema": "DBT_CLAIRE", "name": "MRR", "comment": null, "owner": "TRANSFORMER"}, "columns": {"ID": {"type": "TEXT", "comment": null, "index": 1, "name": "ID"}, "DATE_MONTH": {"type": "TIMESTAMP_NTZ", "comment": null, "index": 2, "name": "DATE_MONTH"}, "CUSTOMER_ID": {"type": "NUMBER", "comment": null, "index": 3, "name": "CUSTOMER_ID"}, "MRR": {"type": "FLOAT", "comment": null, "index": 4, "name": "MRR"}, "IS_ACTIVE": {"type": "BOOLEAN", "comment": null, "index": 5, "name": "IS_ACTIVE"}, "FIRST_ACTIVE_MONTH": {"type": "TIMESTAMP_NTZ", "comment": null, "index": 6, "name": "FIRST_ACTIVE_MONTH"}, "LAST_ACTIVE_MONTH": {"type": "TIMESTAMP_NTZ", "comment": null, "index": 7, "name": "LAST_ACTIVE_MONTH"}, "IS_FIRST_MONTH": {"type": "BOOLEAN", "comment": null, "index": 8, "name": "IS_FIRST_MONTH"}, "IS_LAST_MONTH": {"type": "BOOLEAN", "comment": null, "index": 9, "name": "IS_LAST_MONTH"}, "PREVIOUS_MONTH_IS_ACTIVE": {"type": "BOOLEAN", "comment": null, "index": 10, "name": "PREVIOUS_MONTH_IS_ACTIVE"}, "PREVIOUS_MONTH_MRR": {"type": "FLOAT", "comment": null, "index": 11, "name": "PREVIOUS_MONTH_MRR"}, "MRR_CHANGE": {"type": "FLOAT", "comment": null, "index": 12, "name": "MRR_CHANGE"}, "CHANGE_CATEGORY": {"type": "TEXT", "comment": null, "index": 13, "name": "CHANGE_CATEGORY"}, "RENEWAL_AMOUNT": {"type": "FLOAT", "comment": null, "index": 14, "name": "RENEWAL_AMOUNT"}}, "stats": {"has_stats": {"id": "has_stats", "label": "Has Stats?", "value": false, "description": "Indicates whether there are statistics for this table", "include": false}}, "unique_id": "model.acme.mrr"}, "seed.acme.subscription_periods": {"metadata": {"type": "BASE TABLE", "database": "ANALYTICS", "schema": "DBT_CLAIRE", "name": "SUBSCRIPTION_PERIODS", "comment": null, "owner": "TRANSFORMER"}, "columns": {"SUBSCRIPTION_ID": {"type": "NUMBER", "comment": null, "index": 1, "name": "SUBSCRIPTION_ID"}, "CUSTOMER_ID": {"type": "NUMBER", "comment": null, "index": 2, "name": "CUSTOMER_ID"}, "START_DATE": {"type": "DATE", "comment": null, "index": 3, "name": "START_DATE"}, "END_DATE": {"type": "DATE", "comment": null, "index": 4, "name": "END_DATE"}, "MONTHLY_AMOUNT": {"type": "NUMBER", "comment": null, "index": 5, "name": "MONTHLY_AMOUNT"}}, "stats": {"bytes": {"id": "bytes", "label": "Approximate Size", "value": 2560.0, "description": "Approximate size of the table as reported by Snowflake", "include": true}, "row_count": {"id": "row_count", "label": "Row Count", "value": 121.0, "description": "An approximate count of rows in this table", "include": true}, "last_modified": {"id": "last_modified", "label": "Last Modified", "value": "2021-03-04 18:13UTC", "description": "The timestamp for last update/change", "include": true}, "has_stats": {"id": "has_stats", "label": "Has Stats?", "value": true, "description": "Indicates whether there are statistics for this table", "include": false}}, "unique_id": "seed.acme.subscription_periods"}, "model.acme.customer_churn_month": {"metadata": {"type": "VIEW", "database": "ANALYTICS", "schema": "DBT_CLAIRE", "name": "CUSTOMER_CHURN_MONTH", "comment": null, "owner": "TRANSFORMER"}, "columns": {"DATE_MONTH": {"type": "DATE", "comment": null, "index": 1, "name": "DATE_MONTH"}, "CUSTOMER_ID": {"type": "NUMBER", "comment": null, "index": 2, "name": "CUSTOMER_ID"}, "MRR": {"type": "FLOAT", "comment": null, "index": 3, "name": "MRR"}, "IS_ACTIVE": {"type": "BOOLEAN", "comment": null, "index": 4, "name": "IS_ACTIVE"}, "FIRST_ACTIVE_MONTH": {"type": "TIMESTAMP_NTZ", "comment": null, "index": 5, "name": "FIRST_ACTIVE_MONTH"}, "LAST_ACTIVE_MONTH": {"type": "TIMESTAMP_NTZ", "comment": null, "index": 6, "name": "LAST_ACTIVE_MONTH"}, "IS_FIRST_MONTH": {"type": "BOOLEAN", "comment": null, "index": 7, "name": "IS_FIRST_MONTH"}, "IS_LAST_MONTH": {"type": "BOOLEAN", "comment": null, "index": 8, "name": "IS_LAST_MONTH"}}, "stats": {"has_stats": {"id": "has_stats", "label": "Has Stats?", "value": false, "description": "Indicates whether there are statistics for this table", "include": false}}, "unique_id": "model.acme.customer_churn_month"}, "model.acme.util_months": {"metadata": {"type": "VIEW", "database": "ANALYTICS", "schema": "DBT_CLAIRE", "name": "UTIL_MONTHS", "comment": null, "owner": "TRANSFORMER"}, "columns": {"DATE_MONTH": {"type": "TIMESTAMP_NTZ", "comment": null, "index": 1, "name": "DATE_MONTH"}}, "stats": {"has_stats": {"id": "has_stats", "label": "Has Stats?", "value": false, "description": "Indicates whether there are statistics for this table", "include": false}}, "unique_id": "model.acme.util_months"}}, "sources": {}, "errors": null} -------------------------------------------------------------------------------- /docs/run_results.json: -------------------------------------------------------------------------------- 1 | {"metadata": {"dbt_schema_version": "https://schemas.getdbt.com/dbt/run-results/v1.json", "dbt_version": "0.19.0", "generated_at": "2021-03-04T18:15:07.609849Z", "invocation_id": "f5a37ed7-b84a-4b6d-999d-2203e09421d7", "env": {}}, "results": [{"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:05.093260Z", "completed_at": "2021-03-04T18:15:05.127938Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:05.128220Z", "completed_at": "2021-03-04T18:15:05.128239Z"}], "thread_id": "Thread-2", "execution_time": 0.03580594062805176, "message": null, "adapter_response": {}, "unique_id": "seed.acme.subscription_periods"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:05.130007Z", "completed_at": "2021-03-04T18:15:05.164669Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:05.165270Z", "completed_at": "2021-03-04T18:15:05.165280Z"}], "thread_id": "Thread-4", "execution_time": 0.036279916763305664, "message": null, "adapter_response": {}, "unique_id": "test.acme.dbt_utils_expression_is_true_subscription_periods_date_trunc_month_end_date_end_date"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:05.146915Z", "completed_at": "2021-03-04T18:15:05.166959Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:05.167551Z", "completed_at": "2021-03-04T18:15:05.167559Z"}], "thread_id": "Thread-6", "execution_time": 0.022797107696533203, "message": null, "adapter_response": {}, "unique_id": "test.acme.dbt_utils_mutually_exclusive_ranges_subscription_periods_start_date__customer_id__end_date"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:05.146573Z", "completed_at": "2021-03-04T18:15:05.167300Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:05.167805Z", "completed_at": "2021-03-04T18:15:05.167812Z"}], "thread_id": "Thread-5", "execution_time": 0.038223981857299805, "message": null, "adapter_response": {}, "unique_id": "test.acme.dbt_utils_expression_is_true_subscription_periods_date_trunc_month_start_date_start_date"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:05.093139Z", "completed_at": "2021-03-04T18:15:06.710446Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:06.710848Z", "completed_at": "2021-03-04T18:15:06.710864Z"}], "thread_id": "Thread-1", "execution_time": 2.3024630546569824, "message": null, "adapter_response": {}, "unique_id": "model.acme.util_months"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.396574Z", "completed_at": "2021-03-04T18:15:07.409276Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.409686Z", "completed_at": "2021-03-04T18:15:07.409697Z"}], "thread_id": "Thread-8", "execution_time": 0.014022111892700195, "message": null, "adapter_response": {}, "unique_id": "model.acme.customer_revenue_by_month"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.411129Z", "completed_at": "2021-03-04T18:15:07.431096Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.431341Z", "completed_at": "2021-03-04T18:15:07.431350Z"}], "thread_id": "Thread-2", "execution_time": 0.020807981491088867, "message": null, "adapter_response": {}, "unique_id": "model.acme.customer_churn_month"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.422615Z", "completed_at": "2021-03-04T18:15:07.431940Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.432453Z", "completed_at": "2021-03-04T18:15:07.432461Z"}], "thread_id": "Thread-7", "execution_time": 0.010519027709960938, "message": null, "adapter_response": {}, "unique_id": "test.acme.dbt_utils_unique_combination_of_columns_customer_revenue_by_month_customer_id__date_month"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.440238Z", "completed_at": "2021-03-04T18:15:07.462684Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.463170Z", "completed_at": "2021-03-04T18:15:07.463179Z"}], "thread_id": "Thread-5", "execution_time": 0.025738000869750977, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_customer_churn_month_customer_id"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.433533Z", "completed_at": "2021-03-04T18:15:07.462966Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.465139Z", "completed_at": "2021-03-04T18:15:07.465146Z"}], "thread_id": "Thread-6", "execution_time": 0.03288125991821289, "message": null, "adapter_response": {}, "unique_id": "model.acme.mrr"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.456304Z", "completed_at": "2021-03-04T18:15:07.473673Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.478710Z", "completed_at": "2021-03-04T18:15:07.478720Z"}], "thread_id": "Thread-1", "execution_time": 0.025011301040649414, "message": null, "adapter_response": {}, "unique_id": "test.acme.unique_customer_churn_month_customer_id"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.467491Z", "completed_at": "2021-03-04T18:15:07.480056Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.489567Z", "completed_at": "2021-03-04T18:15:07.489578Z"}], "thread_id": "Thread-8", "execution_time": 0.053089141845703125, "message": null, "adapter_response": {}, "unique_id": "test.acme.dbt_utils_expression_is_true_mrr_date_month_date_trunc_month_current_date_"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.479377Z", "completed_at": "2021-03-04T18:15:07.526546Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.530390Z", "completed_at": "2021-03-04T18:15:07.530398Z"}], "thread_id": "Thread-4", "execution_time": 0.055066823959350586, "message": null, "adapter_response": {}, "unique_id": "test.acme.dbt_utils_unique_combination_of_columns_mrr_customer_id__date_month"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.480494Z", "completed_at": "2021-03-04T18:15:07.528840Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.531283Z", "completed_at": "2021-03-04T18:15:07.531290Z"}], "thread_id": "Thread-2", "execution_time": 0.06297683715820312, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_customer_id"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.480833Z", "completed_at": "2021-03-04T18:15:07.529914Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.531924Z", "completed_at": "2021-03-04T18:15:07.531952Z"}], "thread_id": "Thread-7", "execution_time": 0.06302475929260254, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_date_month"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.489445Z", "completed_at": "2021-03-04T18:15:07.530171Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.532165Z", "completed_at": "2021-03-04T18:15:07.532171Z"}], "thread_id": "Thread-5", "execution_time": 0.06251287460327148, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_id"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.489331Z", "completed_at": "2021-03-04T18:15:07.530817Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.532741Z", "completed_at": "2021-03-04T18:15:07.532748Z"}], "thread_id": "Thread-3", "execution_time": 0.06319189071655273, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_first_active_month"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.489895Z", "completed_at": "2021-03-04T18:15:07.531468Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.541541Z", "completed_at": "2021-03-04T18:15:07.541548Z"}], "thread_id": "Thread-6", "execution_time": 0.06341385841369629, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_is_active"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.531092Z", "completed_at": "2021-03-04T18:15:07.549582Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.552546Z", "completed_at": "2021-03-04T18:15:07.552555Z"}], "thread_id": "Thread-1", "execution_time": 0.026205778121948242, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_is_first_month"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.541755Z", "completed_at": "2021-03-04T18:15:07.553569Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.562298Z", "completed_at": "2021-03-04T18:15:07.562308Z"}], "thread_id": "Thread-8", "execution_time": 0.05376005172729492, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_is_last_month"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.553489Z", "completed_at": "2021-03-04T18:15:07.592040Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.602320Z", "completed_at": "2021-03-04T18:15:07.602346Z"}], "thread_id": "Thread-4", "execution_time": 0.0528719425201416, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_last_active_month"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.554039Z", "completed_at": "2021-03-04T18:15:07.601217Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.603320Z", "completed_at": "2021-03-04T18:15:07.603328Z"}], "thread_id": "Thread-2", "execution_time": 0.05304408073425293, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_mrr"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.554674Z", "completed_at": "2021-03-04T18:15:07.601743Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.604003Z", "completed_at": "2021-03-04T18:15:07.604010Z"}], "thread_id": "Thread-7", "execution_time": 0.05277585983276367, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_mrr_change"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.554783Z", "completed_at": "2021-03-04T18:15:07.602737Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.604795Z", "completed_at": "2021-03-04T18:15:07.604802Z"}], "thread_id": "Thread-5", "execution_time": 0.05331110954284668, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_previous_month_is_active"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.570033Z", "completed_at": "2021-03-04T18:15:07.603674Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.605324Z", "completed_at": "2021-03-04T18:15:07.605330Z"}], "thread_id": "Thread-6", "execution_time": 0.05290484428405762, "message": null, "adapter_response": {}, "unique_id": "test.acme.unique_mrr_id"}, {"status": "success", "timing": [{"name": "compile", "started_at": "2021-03-04T18:15:07.562531Z", "completed_at": "2021-03-04T18:15:07.604202Z"}, {"name": "execute", "started_at": "2021-03-04T18:15:07.605821Z", "completed_at": "2021-03-04T18:15:07.605843Z"}], "thread_id": "Thread-3", "execution_time": 0.053739070892333984, "message": null, "adapter_response": {}, "unique_id": "test.acme.not_null_mrr_previous_month_mrr"}], "elapsed_time": 4.924256086349487, "args": {"log_format": "default", "write_json": true, "profiles_dir": "/Users/claire/.dbt", "use_cache": true, "compile": true, "version_check": true, "which": "generate", "rpc_method": "docs.generate"}} -------------------------------------------------------------------------------- /macros/grant_select_on_schema.sql: -------------------------------------------------------------------------------- 1 | {% macro grant_select_on_schemas(schemas, role) %} 2 | {% for schema in schemas %} 3 | grant usage on schema {{ schema }} to role {{ role }}; 4 | grant select on all tables in schema {{ schema }} to role {{ role }}; 5 | grant select on all views in schema {{ schema }} to role {{ role }}; 6 | grant select on future tables in schema {{ schema }} to role {{ role }}; 7 | grant select on future views in schema {{ schema }} to role {{ role }}; 8 | {% endfor %} 9 | {% endmacro %} 10 | -------------------------------------------------------------------------------- /models/customer_churn_month.sql: -------------------------------------------------------------------------------- 1 | with mrr as ( 2 | 3 | select * from {{ ref('customer_revenue_by_month') }} 4 | 5 | ), 6 | 7 | -- row for month *after* last month of activity 8 | joined as ( 9 | 10 | select 11 | dateadd(month, 1, date_month)::date as date_month, 12 | customer_id, 13 | 0::float as mrr, 14 | false as is_active, 15 | first_active_month, 16 | last_active_month, 17 | false as is_first_month, 18 | false as is_last_month 19 | 20 | from mrr 21 | 22 | where is_last_month 23 | 24 | ) 25 | 26 | select * from joined 27 | -------------------------------------------------------------------------------- /models/customer_revenue_by_month.sql: -------------------------------------------------------------------------------- 1 | with subscription_periods as ( 2 | 3 | select * from {{ ref('subscription_periods') }} 4 | 5 | ), 6 | 7 | months as ( 8 | 9 | select * from {{ ref('util_months') }} 10 | 11 | ), 12 | 13 | -- determine when a given account had its first and last (or most recent) month 14 | customers as ( 15 | 16 | select 17 | customer_id, 18 | date_trunc('month', min(start_date)) as date_month_start, 19 | date_trunc('month', max(end_date)) as date_month_end 20 | 21 | from subscription_periods 22 | 23 | group by 1 24 | 25 | ), 26 | 27 | -- create one record per month between a customer's first and last month 28 | -- (example of a date spine) 29 | customer_months as ( 30 | 31 | select 32 | customers.customer_id, 33 | months.date_month 34 | 35 | from customers 36 | 37 | inner join months 38 | -- all months after start date 39 | on months.date_month >= customers.date_month_start 40 | -- and before end date 41 | and months.date_month < customers.date_month_end 42 | 43 | ), 44 | 45 | -- join the account-month spine to MRR base model, pulling through most recent dates 46 | -- and plan info for month rows that have no invoices (i.e. churns) 47 | joined as ( 48 | 49 | select 50 | customer_months.date_month, 51 | customer_months.customer_id, 52 | coalesce(subscription_periods.monthly_amount, 0) as mrr 53 | 54 | from customer_months 55 | 56 | left join subscription_periods 57 | on customer_months.customer_id = subscription_periods.customer_id 58 | -- month is after a subscription start date 59 | and customer_months.date_month >= subscription_periods.start_date 60 | -- month is before a subscription end date (and handle null case) 61 | and (customer_months.date_month < subscription_periods.end_date 62 | or subscription_periods.end_date is null) 63 | 64 | ), 65 | 66 | final as ( 67 | 68 | select 69 | date_month, 70 | customer_id, 71 | mrr, 72 | 73 | mrr > 0 as is_active, 74 | 75 | -- calculate first and last months 76 | min(case when is_active then date_month end) over ( 77 | partition by customer_id 78 | ) as first_active_month, 79 | 80 | max(case when is_active then date_month end) over ( 81 | partition by customer_id 82 | ) as last_active_month, 83 | 84 | -- calculate if this record is the first or last month 85 | first_active_month = date_month as is_first_month, 86 | last_active_month = date_month as is_last_month 87 | 88 | from joined 89 | 90 | ) 91 | 92 | select * from final 93 | -------------------------------------------------------------------------------- /models/mrr.md: -------------------------------------------------------------------------------- 1 | {% docs mrr %} 2 | This model represents one record per month, per account (months have been filled 3 | in to include any periods of inactivity). 4 | 5 | This model classifies each month as one of: `new`, `reactivation`, `upgrade`, 6 | `downgrade`, or `churn`. 7 | 8 | {% enddocs %} 9 | 10 | 11 | {% docs change_category %} 12 | 13 | | Category | Definition | 14 | |----------------|---------------------------------------------------------------------------------------------------------| 15 | | new | The customer is a new customer that has not had a previous subscription | 16 | | churn | Last month the customer paid for a subscription, but this month is not. A customer can churn many times | 17 | | upgrade | The customer has increased their usage and is now paying you more money per month | 18 | | downgrade | The customer has decreased their usage and is now paying you less money per month | 19 | | reactivation | A previously churned customer has started subscribing again | 20 | | (null) | No change compared to last month | 21 | 22 | 23 | {% enddocs %} 24 | -------------------------------------------------------------------------------- /models/mrr.sql: -------------------------------------------------------------------------------- 1 | with unioned as ( 2 | 3 | select * from {{ ref('customer_revenue_by_month') }} 4 | 5 | union all 6 | 7 | select * from {{ ref('customer_churn_month') }} 8 | 9 | ), 10 | 11 | -- get prior month MRR and calculate MRR change 12 | mrr_with_changes as ( 13 | 14 | select 15 | *, 16 | 17 | coalesce( 18 | lag(is_active) over (partition by customer_id order by date_month), 19 | false 20 | ) as previous_month_is_active, 21 | 22 | coalesce( 23 | lag(mrr) over (partition by customer_id order by date_month), 24 | 0 25 | ) as previous_month_mrr, 26 | 27 | mrr - previous_month_mrr as mrr_change 28 | 29 | from unioned 30 | 31 | ), 32 | 33 | -- classify months as new, churn, reactivation, upgrade, downgrade (or null) 34 | -- also add an ID column 35 | final as ( 36 | 37 | select 38 | {{ dbt_utils.surrogate_key('date_month', 'customer_id') }} as id, 39 | 40 | *, 41 | 42 | case 43 | when is_first_month 44 | then 'new' 45 | when not(is_active) and previous_month_is_active 46 | then 'churn' 47 | when is_active and not(previous_month_is_active) 48 | then 'reactivation' 49 | when mrr_change > 0 then 'upgrade' 50 | when mrr_change < 0 then 'downgrade' 51 | end as change_category, 52 | 53 | least(mrr, previous_month_mrr) as renewal_amount 54 | 55 | from mrr_with_changes 56 | 57 | ) 58 | 59 | select * from final 60 | -------------------------------------------------------------------------------- /models/mrr.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: mrr 5 | description: "{{ doc('mrr') }}" 6 | tests: 7 | - dbt_utils.unique_combination_of_columns: 8 | combination_of_columns: 9 | - customer_id 10 | - date_month 11 | - dbt_utils.expression_is_true: 12 | expression: "date_month <= date_trunc('month', current_date)" 13 | 14 | columns: 15 | - name: id 16 | tests: 17 | - unique 18 | - not_null 19 | 20 | - name: date_month 21 | tests: 22 | - not_null 23 | 24 | - name: customer_id 25 | tests: 26 | - not_null 27 | 28 | - name: mrr 29 | description: Monthly recurring revenue in dollars. 30 | tests: 31 | - not_null 32 | 33 | - name: is_active 34 | description: True when the account has an mrr > 0 35 | tests: 36 | - not_null 37 | 38 | - name: first_active_month 39 | description: The first month an account was active 40 | tests: 41 | - not_null 42 | 43 | - name: last_active_month 44 | description: The last month an account was active 45 | tests: 46 | - not_null 47 | 48 | - name: is_first_month 49 | tests: 50 | - not_null 51 | 52 | - name: is_last_month 53 | tests: 54 | - not_null 55 | 56 | - name: previous_month_is_active 57 | tests: 58 | - not_null 59 | 60 | - name: previous_month_mrr 61 | tests: 62 | - not_null 63 | 64 | - name: mrr_change 65 | tests: 66 | - not_null 67 | 68 | - name: change_category 69 | description: "{{ doc('change_category') }}" 70 | -------------------------------------------------------------------------------- /models/overview.md: -------------------------------------------------------------------------------- 1 | {% docs __overview__ %} 2 | # Monthly Recurring Revenue (MRR) playbook. 3 | This dbt project is a worked example to demonstrate how to model subscription 4 | revenue. **Check out the full write-up [here](https://blog.getdbt.com/modeling-subscription-revenue/), 5 | as well as the repo for this project [here](https://github.com/fishtown-analytics/mrr-playbook/).** 6 | 7 | Note that this project is not a package -- it is not intended to be installed in 8 | your own dbt project, but instead provides a good starting point for building 9 | similar data models for your own business. 10 | 11 | The SQL in this project is compatible with Snowflake¹. 12 | 13 | If you want to run this project yourself to play with it (assuming you have 14 | dbt installed): 15 | 1. Clone [this repo](https://github.com/fishtown-analytics/mrr-playbook). 16 | 2. Create a profile named `playbook`, or update the `profile:` key in the 17 | `dbt_project.yml` file to point to an existing profile ([docs](https://docs.getdbt.com/docs/configure-your-profile)). 18 | 3. Run `dbt deps`. 19 | 4. Run `dbt seed`. 20 | 5. Run `dbt run` -- if you are using a warehouse other than Snowflake, you may 21 | find that you have to update some SQL to be compatible with your warehouse. 22 | 6. Run `dbt test`. 23 | ----- 24 | 1. We decided to _not_ make the SQL multi-warehouse compatible since this project 25 | is intended to be a demonstration, rather than a package. Making this project 26 | multi-warehouse compatible would complicate the SQL. 27 | 28 | {% enddocs %} 29 | -------------------------------------------------------------------------------- /models/schema.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: subscription_periods 5 | tests: 6 | # test that a customer can only have one active subscription at a time 7 | - dbt_utils.mutually_exclusive_ranges: 8 | lower_bound_column: start_date 9 | upper_bound_column: end_date 10 | partition_by: customer_id 11 | # test that the start date of a subscription is the first of the month 12 | - dbt_utils.expression_is_true: 13 | expression: date_trunc('month', start_date) = start_date 14 | # test that the end date of a subscription is the first of the month 15 | - dbt_utils.expression_is_true: 16 | expression: date_trunc('month', end_date) = end_date 17 | 18 | 19 | - name: customer_revenue_by_month 20 | tests: 21 | - dbt_utils.unique_combination_of_columns: 22 | combination_of_columns: 23 | - customer_id 24 | - date_month 25 | 26 | - name: customer_churn_month 27 | columns: 28 | - name: customer_id 29 | tests: 30 | - unique 31 | - not_null 32 | -------------------------------------------------------------------------------- /models/utils/util_months.sql: -------------------------------------------------------------------------------- 1 | {{ dbt_utils.date_spine( 2 | datepart="month", 3 | start_date="'2018-01-01'", 4 | end_date="date_trunc('month', current_date)" 5 | ) 6 | }} 7 | -------------------------------------------------------------------------------- /packages.yml: -------------------------------------------------------------------------------- 1 | packages: 2 | - package: dbt-labs/dbt_utils 3 | version: 0.8.0 4 | --------------------------------------------------------------------------------