Filters
149 |150 | Show users who have taken each of these actions at least the chosen number of times. 151 |
152 | 153 |├── .DS_Store ├── retention_playbook ├── .DS_Store ├── metrics_that_matter_p1 │ ├── postgres.sql │ └── presentation.html ├── metrics_that_matter_p2 │ ├── postgres.sql │ └── presentation.html ├── describing_retention │ ├── postgres.sql │ └── presentation.html └── retention_cohorts │ ├── postgres.sql │ └── presentation.html ├── user_behavior_playbook ├── .DS_Store ├── measuring_feature_use │ ├── presentation.html │ └── postgres.sql ├── how_effective_are_interventions │ ├── presentation.html │ └── postgres.sql ├── how_users_move_through_your_product │ ├── postgres.sql │ └── presentation.html └── when_do_users_slip_away │ ├── postgres.sql │ └── presentation.html ├── LICENSE └── README.md /.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/mode/playbook/HEAD/.DS_Store -------------------------------------------------------------------------------- /retention_playbook/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/mode/playbook/HEAD/retention_playbook/.DS_Store -------------------------------------------------------------------------------- /user_behavior_playbook/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/mode/playbook/HEAD/user_behavior_playbook/.DS_Store -------------------------------------------------------------------------------- /user_behavior_playbook/measuring_feature_use/presentation.html: -------------------------------------------------------------------------------- 1 |
2 | -------------------------------------------------------------------------------- /user_behavior_playbook/how_effective_are_interventions/presentation.html: -------------------------------------------------------------------------------- 1 | 2 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2017 Mode Analytics, Inc. 2 | 3 | Permission is hereby granted, free of charge, to any person obtaining a copy 4 | of this software and associated documentation files (the "Software"), to deal 5 | in the Software without restriction, including without limitation the rights 6 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 7 | copies of the Software, and to permit persons to whom the Software is 8 | furnished to do so, subject to the following conditions: 9 | 10 | The above copyright notice and this permission notice shall be included in all 11 | copies or substantial portions of the Software. 12 | 13 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 14 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 15 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 16 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 17 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 18 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 19 | SOFTWARE. -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | playbook 2 | ======== 3 | 4 | Welcome to the Mode Playbook! Playbook is a repository of open-source SQL queries and visualizations you can tailor to your data. All the reports are designed to be used in [Mode](http://www.modeanalytics.com/), and live examples are available in Mode and on the [Playbook](http://about.modeanalytics.com/playbook) page. 5 | 6 |  7 | 8 | 9 | Playbook reports are designed to answer common questions that many companies ask. Each report provides access to the raw SQL query and the HTML, CSS, and Javascript code that powers the visualization. 10 | 11 | To read more, see the [Playbook](http://about.modeanalytics.com/playbook) page on Mode. [Additional documentation](https://modeanalytics.zendesk.com/hc/en-us/articles/203511970-Playbook-Overview) is also available. 12 | 13 | If you have comments, suggestions for improvements, requests for additional reports—or best of all, analysis that you too would like to open source—we'd love to hear from you. We can be reached at [hi@modeanalytics.com](mailto:hi@modeanalytics.com). 14 | -------------------------------------------------------------------------------- /retention_playbook/metrics_that_matter_p1/postgres.sql: -------------------------------------------------------------------------------- 1 | -- For details on how to use this report, visit 2 | -- https://modeanalytics.zendesk.com/hc/en-us/articles/203317944 3 | 4 | WITH 5 | users AS ( 6 | 7 | SELECT user_id, 8 | activated_at 9 | FROM tutorial.playbook_users 10 | 11 | ), 12 | 13 | events AS ( 14 | 15 | SELECT user_id, 16 | event_name, 17 | occurred_at 18 | FROM tutorial.playbook_events 19 | ) 20 | 21 | SELECT u.user_id, 22 | u.activated_at, 23 | MAX(CASE WHEN e.occurred_at >= u.activated_at + INTERVAL '7 DAY' THEN 1 ELSE 0 END) AS retained, 24 | COUNT(CASE WHEN e.event_name = 'home_page' THEN e.user_id ELSE NULL END) AS home_page_visits, 25 | COUNT(CASE WHEN e.event_name = 'search_run' THEN e.user_id ELSE NULL END) AS searches, 26 | COUNT(CASE WHEN e.event_name = 'send_message' THEN e.user_id ELSE NULL END) AS messages, 27 | COUNT(CASE WHEN e.event_name = 'like_message' THEN e.user_id ELSE NULL END) AS like_message, 28 | COUNT(CASE WHEN e.event_name = 'view_inbox' THEN e.user_id ELSE NULL END) AS view_inbox 29 | FROM users u 30 | JOIN events e 31 | ON e.user_id = u.user_id 32 | AND e.occurred_at >= u.activated_at 33 | AND e.occurred_at < u.activated_at + INTERVAL '14 DAY' 34 | GROUP BY 1,2 -------------------------------------------------------------------------------- /retention_playbook/metrics_that_matter_p2/postgres.sql: -------------------------------------------------------------------------------- 1 | -- For details on how to use this report, visit 2 | -- https://modeanalytics.zendesk.com/hc/en-us/articles/203317944 3 | 4 | WITH 5 | users AS ( 6 | 7 | SELECT user_id, 8 | activated_at 9 | FROM tutorial.playbook_users 10 | 11 | ), 12 | 13 | events AS ( 14 | 15 | SELECT user_id, 16 | event_name, 17 | occurred_at 18 | FROM tutorial.playbook_events 19 | ) 20 | 21 | SELECT u.user_id, 22 | u.activated_at, 23 | MAX(CASE WHEN e.occurred_at >= u.activated_at + INTERVAL '7 DAY' THEN 1 ELSE 0 END) AS retained, 24 | COUNT(CASE WHEN e.event_name = 'home_page' THEN e.user_id ELSE NULL END) AS home_page_visits, 25 | COUNT(CASE WHEN e.event_name = 'search_run' THEN e.user_id ELSE NULL END) AS searches, 26 | COUNT(CASE WHEN e.event_name = 'send_message' THEN e.user_id ELSE NULL END) AS messages, 27 | COUNT(CASE WHEN e.event_name = 'like_message' THEN e.user_id ELSE NULL END) AS like_message, 28 | COUNT(CASE WHEN e.event_name = 'view_inbox' THEN e.user_id ELSE NULL END) AS view_inbox 29 | FROM users u 30 | JOIN events e 31 | ON e.user_id = u.user_id 32 | AND e.occurred_at >= u.activated_at 33 | AND e.occurred_at < u.activated_at + INTERVAL '14 DAY' 34 | GROUP BY 1,2 -------------------------------------------------------------------------------- /retention_playbook/describing_retention/postgres.sql: -------------------------------------------------------------------------------- 1 | -- For details on how to use this report, visit 2 | -- https://modeanalytics.zendesk.com/hc/en-us/articles/203484670 3 | 4 | WITH 5 | 6 | users AS ( 7 | SELECT customer_id AS user_id, 8 | signup_date AS activated_at 9 | FROM benn.sample_customer_table 10 | ), 11 | 12 | events AS ( 13 | SELECT customer_id AS user_id, 14 | event_name, 15 | event_date AS occurred_at 16 | FROM benn.sample_event_table 17 | ) 18 | 19 | SELECT DATE_TRUNC('{{time_interval}}',u.activated_at) AS signup_date, 20 | 21 | {% if time_interval == 'month' %} 22 | (EXTRACT('year' FROM e.occurred_at) - EXTRACT('year' FROM u.activated_at)) * 12 + 23 | (EXTRACT('month' FROM e.occurred_at) - EXTRACT('month' FROM u.activated_at)) - 24 | CASE WHEN (CEILING(DATE_PART('day',e.occurred_at) - DATE_PART('day',u.activated_at))) < 0 THEN 1 ELSE 0 END AS user_period, 25 | {% elsif time_interval == 'week' %} 26 | TRUNC(DATE_PART('day',e.occurred_at - u.activated_at)/7) AS user_period, 27 | {% endif %} 28 | 29 | COUNT(DISTINCT e.user_id) AS retained_users 30 | FROM users u 31 | JOIN events e 32 | ON e.user_id = u.user_id 33 | AND e.occurred_at >= u.activated_at 34 | AND e.occurred_at <= '2014-10-31'::TIMESTAMP 35 | WHERE u.activated_at >= '2014-10-31'::TIMESTAMP - INTERVAL '11 {{time_interval}}' 36 | AND u.activated_at <= '2014-10-31'::TIMESTAMP 37 | GROUP BY 1,2 38 | ORDER BY 1,2 39 | 40 | {% form %} 41 | 42 | time_interval: 43 | type: select 44 | default: month 45 | options: [[week, week], 46 | [month, month] 47 | ] 48 | 49 | {% endform %} -------------------------------------------------------------------------------- /user_behavior_playbook/measuring_feature_use/postgres.sql: -------------------------------------------------------------------------------- 1 | -- For details on how to use this report, visit 2 | -- https://modeanalytics.zendesk.com/hc/en-us/articles/203326184 3 | 4 | WITH 5 | 6 | users AS ( 7 | 8 | SELECT user_id, 9 | activated_at 10 | FROM tutorial.playbook_users 11 | ), 12 | 13 | events AS ( 14 | SELECT user_id, 15 | event_name, 16 | occurred_at 17 | FROM tutorial.playbook_events 18 | ) 19 | 20 | SELECT time_id, 21 | 22 | 23 | 24 | home_page_visits_users AS home_page_visits, 25 | searches_users AS searches, 26 | messages_users AS messages, 27 | like_message_users AS like_messages, 28 | view_inbox_users AS view_inbox 29 | 30 | 31 | 32 | FROM ( 33 | SELECT DATE_TRUNC('day',e.occurred_at) AS time_id, 34 | COUNT(DISTINCT CASE WHEN e.event_name = 'home_page' THEN e.user_id ELSE NULL END) AS home_page_visits_users, 35 | COUNT(DISTINCT CASE WHEN e.event_name = 'search_run' THEN e.user_id ELSE NULL END) AS searches_users, 36 | COUNT(DISTINCT CASE WHEN e.event_name = 'send_message' THEN e.user_id ELSE NULL END) AS messages_users, 37 | COUNT(DISTINCT CASE WHEN e.event_name = 'like_message' THEN e.user_id ELSE NULL END) AS like_message_users, 38 | COUNT(DISTINCT CASE WHEN e.event_name = 'view_inbox' THEN e.user_id ELSE NULL END) AS view_inbox_users, 39 | COUNT(CASE WHEN e.event_name = 'home_page' THEN e.user_id ELSE NULL END) AS home_page_visits, 40 | COUNT(CASE WHEN e.event_name = 'search_run' THEN e.user_id ELSE NULL END) AS searches, 41 | COUNT(CASE WHEN e.event_name = 'send_message' THEN e.user_id ELSE NULL END) AS messages, 42 | COUNT(CASE WHEN e.event_name = 'like_message' THEN e.user_id ELSE NULL END) AS like_message, 43 | COUNT(CASE WHEN e.event_name = 'view_inbox' THEN e.user_id ELSE NULL END) AS view_inbox 44 | FROM users u 45 | JOIN events e 46 | ON e.user_id = u.user_id 47 | AND e.occurred_at >= '2014-01-01' 48 | AND e.occurred_at <= '2014-10-31' 49 | GROUP BY 1 50 | ORDER BY 1 51 | ) z -------------------------------------------------------------------------------- /user_behavior_playbook/how_users_move_through_your_product/postgres.sql: -------------------------------------------------------------------------------- 1 | -- For details on how to use this report, visit 2 | -- https://modeanalytics.zendesk.com/hc/en-us/articles/203501570 3 | 4 | WITH 5 | 6 | events AS ( 7 | 8 | SELECT user_id, 9 | event_name, 10 | occurred_at 11 | FROM tutorial.playbook_events 12 | WHERE event_type = 'engagement' 13 | ) 14 | 15 | SELECT e1, 16 | e2, 17 | e3, 18 | e4, 19 | e5, 20 | COUNT(*) AS occurrances 21 | FROM ( 22 | --Pivot out first five events in each session 23 | SELECT user_id, 24 | session, 25 | MAX(CASE WHEN event_number = 1 THEN event_name ELSE NULL END) AS e1, 26 | MAX(CASE WHEN event_number = 2 THEN event_name ELSE NULL END) AS e2, 27 | MAX(CASE WHEN event_number = 3 THEN event_name ELSE NULL END) AS e3, 28 | MAX(CASE WHEN event_number = 4 THEN event_name ELSE NULL END) AS e4, 29 | MAX(CASE WHEN event_number = 5 THEN event_name ELSE NULL END) AS e5 30 | FROM ( 31 | -- Find event number in session 32 | SELECT z.*, 33 | ROW_NUMBER() OVER (PARTITION BY user_id, session ORDER BY occurred_at) AS event_number 34 | FROM ( 35 | -- Sum breaks to find sessions 36 | SELECT y.*, 37 | SUM(break) OVER (ORDER BY user_id,occurred_at ROWS UNBOUNDED PRECEDING) AS session 38 | FROM ( 39 | -- Add flag if last event was more than 10 minutes ago 40 | SELECT x.*, 41 | CASE WHEN last_event IS NULL OR occurred_at >= last_event + INTERVAL '10 MINUTE' THEN 1 ELSE 0 END AS break 42 | FROM ( 43 | -- Find last event 44 | SELECT *, 45 | LAG(occurred_at,1) OVER (PARTITION BY user_id ORDER BY occurred_at) AS last_event 46 | FROM events 47 | 48 | ) x 49 | ) y 50 | ) z 51 | ) a 52 | WHERE event_number <= 5 53 | GROUP BY 1,2 54 | ) final 55 | GROUP BY 1,2,3,4,5 56 | ORDER BY 6 DESC -------------------------------------------------------------------------------- /user_behavior_playbook/how_effective_are_interventions/postgres.sql: -------------------------------------------------------------------------------- 1 | -- For details on how to use this report, visit 2 | -- https://modeanalytics.zendesk.com/hc/en-us/articles/203501550 3 | 4 | WITH 5 | 6 | users AS ( 7 | 8 | SELECT user_id, 9 | activated_at 10 | FROM tutorial.playbook_users 11 | 12 | ), 13 | 14 | events AS ( 15 | 16 | SELECT user_id, 17 | occurred_at 18 | FROM tutorial.playbook_events 19 | WHERE event_type = 'engagement' 20 | AND event_name = 'login' 21 | 22 | ), 23 | 24 | interventions AS ( 25 | 26 | SELECT user_id, 27 | occurred_at 28 | FROM tutorial.playbook_emails 29 | WHERE action = 'sent_reengagement_email' 30 | ) 31 | 32 | SELECT z.counter AS time_from_event, 33 | COUNT(DISTINCT CASE WHEN z.user_age BETWEEN 31 AND 60 AND z.logged_event = TRUE THEN z.user_id ELSE NULL END)/ 34 | COUNT(DISTINCT CASE WHEN z.user_age BETWEEN 31 AND 60 THEN z.user_id ELSE NULL END)::FLOAT AS "31 to 60 days old", 35 | COUNT(DISTINCT CASE WHEN z.user_age BETWEEN 61 AND 90 AND z.logged_event = TRUE THEN z.user_id ELSE NULL END)/ 36 | COUNT(DISTINCT CASE WHEN z.user_age BETWEEN 61 AND 90 THEN z.user_id ELSE NULL END)::FLOAT AS "61 to 90 days old", 37 | COUNT(DISTINCT CASE WHEN z.user_age BETWEEN 91 AND 150 AND z.logged_event = TRUE THEN z.user_id ELSE NULL END)/ 38 | COUNT(DISTINCT CASE WHEN z.user_age BETWEEN 91 AND 150 THEN z.user_id ELSE NULL END)::FLOAT AS "91 to 150 days old", 39 | COUNT(DISTINCT CASE WHEN z.user_age >= 151 AND z.logged_event = TRUE THEN z.user_id ELSE NULL END)/ 40 | COUNT(DISTINCT CASE WHEN z.user_age >= 151 THEN z.user_id ELSE NULL END)::FLOAT AS "151 days and older" 41 | FROM ( 42 | SELECT u.user_id, 43 | EXTRACT('day' FROM i.occurred_at - u.activated_at) AS user_age, 44 | i.occurred_at, 45 | u.activated_at, 46 | c.counter, 47 | CASE WHEN e.occurred_at IS NOT NULL THEN TRUE ELSE FALSE END AS logged_event 48 | FROM interventions i 49 | JOIN users u 50 | ON u.user_id = i.user_id 51 | AND u.activated_at < i.occurred_at 52 | JOIN (SELECT s.a - 30 AS counter FROM generate_series(0,60) AS s(a)) c 53 | ON c.counter >= -30 54 | AND c.counter <= 30 55 | LEFT JOIN events e 56 | ON e.user_id = i.user_id 57 | AND EXTRACT('day' FROM e.occurred_at - i.occurred_at) = c.counter 58 | WHERE EXTRACT('day' FROM NOW() - i.occurred_at) >= 30 59 | ) z 60 | GROUP BY 1 61 | ORDER BY 1 62 | LIMIT 100 -------------------------------------------------------------------------------- /retention_playbook/retention_cohorts/postgres.sql: -------------------------------------------------------------------------------- 1 | -- For details on how to use this report, visit 2 | -- https://modeanalytics.zendesk.com/hc/en-us/articles/203503600 3 | 4 | WITH 5 | 6 | users AS ( 7 | SELECT user_id, 8 | activated_at 9 | FROM tutorial.playbook_users 10 | ), 11 | 12 | events AS ( 13 | SELECT user_id, 14 | occurred_at, 15 | event_name 16 | FROM tutorial.playbook_events 17 | WHERE event_type = 'engagement' 18 | ) 19 | 20 | SELECT CASE WHEN dow = 0 THEN 'Sunday' 21 | WHEN dow = 1 THEN 'Monday' 22 | WHEN dow = 2 THEN 'Tuesday' 23 | WHEN dow = 3 THEN 'Wednesday' 24 | WHEN dow = 4 THEN 'Thursday' 25 | WHEN dow = 5 THEN 'Friday' 26 | WHEN dow = 6 THEN 'Saturday' 27 | ELSE 'error' END AS "Signup day", 28 | COUNT(*) AS users, 29 | COUNT(CASE WHEN z.activated_at <= NOW() - INTERVAL '2 DAY' AND z.r_1_day > 0 THEN z.user_id ELSE NULL END)/ 30 | (COUNT(CASE WHEN z.activated_at <= NOW() - INTERVAL '2 DAY' THEN z.user_id ELSE NULL END) + 1)::FLOAT AS "1 day retention", 31 | COUNT(CASE WHEN z.activated_at <= NOW() - INTERVAL '14 DAY' AND z.r_7_day > 0 THEN z.user_id ELSE NULL END)/ 32 | (COUNT(CASE WHEN z.activated_at <= NOW() - INTERVAL '14 DAY' THEN z.user_id ELSE NULL END) + 1)::FLOAT AS "7 day retention", 33 | COUNT(CASE WHEN z.activated_at <= NOW() - INTERVAL '21 DAY' AND z.r_14_day > 0 THEN z.user_id ELSE NULL END)/ 34 | (COUNT(CASE WHEN z.activated_at <= NOW() - INTERVAL '21 DAY' THEN z.user_id ELSE NULL END) + 1)::FLOAT AS "14 day retention", 35 | COUNT(CASE WHEN z.activated_at <= NOW() - INTERVAL '35 DAY' AND z.r_28_day > 0 THEN z.user_id ELSE NULL END)/ 36 | (COUNT(CASE WHEN z.activated_at <= NOW() - INTERVAL '35 DAY' THEN z.user_id ELSE NULL END) + 1)::FLOAT AS "28 day retention" 37 | FROM ( 38 | SELECT u.user_id, 39 | EXTRACT('DOW' FROM u.activated_at) AS dow, 40 | u.activated_at, 41 | COUNT(CASE WHEN e.occurred_at >= u.activated_at + INTERVAL '1 DAY' AND e.occurred_at < u.activated_at + INTERVAL '2 DAY' 42 | THEN u.user_id ELSE NULL END) AS r_1_day, 43 | COUNT(CASE WHEN e.occurred_at >= u.activated_at + INTERVAL '7 DAY' AND e.occurred_at < u.activated_at + INTERVAL '14 DAY' 44 | THEN u.user_id ELSE NULL END) AS r_7_day, 45 | COUNT(CASE WHEN e.occurred_at >= u.activated_at + INTERVAL '14 DAY' AND e.occurred_at < u.activated_at + INTERVAL '21 DAY' 46 | THEN u.user_id ELSE NULL END) AS r_14_day, 47 | COUNT(CASE WHEN e.occurred_at >= u.activated_at + INTERVAL '28 DAY' AND e.occurred_at < u.activated_at + INTERVAL '35 DAY' 48 | THEN u.user_id ELSE NULL END) AS r_28_day 49 | FROM users u 50 | LEFT JOIN events e 51 | ON e.user_id = u.user_id 52 | AND e.occurred_at >= u.activated_at 53 | AND e.occurred_at < u.activated_at + INTERVAL '35 DAY' 54 | WHERE u.activated_at IS NOT NULL 55 | GROUP BY 1,2,3 56 | ) z 57 | GROUP BY dow 58 | ORDER BY dow 59 | LIMIT 100 -------------------------------------------------------------------------------- /user_behavior_playbook/when_do_users_slip_away/postgres.sql: -------------------------------------------------------------------------------- 1 | -- For details on how to use this report, visit 2 | -- https://modeanalytics.zendesk.com/hc/en-us/articles/203326234 3 | 4 | 5 | WITH 6 | 7 | events AS ( 8 | 9 | SELECT user_id, 10 | occurred_at 11 | FROM tutorial.playbook_events 12 | WHERE event_name = 'send_message' 13 | 14 | ) 15 | 16 | SELECT days_since_last_event AS "Days since last event", 17 | 18 | 19 | 20 | 21 | COUNT(CASE WHEN event_number BETWEEN 1 AND 5 AND event_number < total_events THEN user_id ELSE NULL END)/ 22 | (COUNT(CASE WHEN event_number BETWEEN 1 AND 5 THEN user_id ELSE NULL END) + 1)::FLOAT AS "1-5", 23 | COUNT(CASE WHEN event_number BETWEEN 6 AND 10 AND event_number < total_events THEN user_id ELSE NULL END)/ 24 | (COUNT(CASE WHEN event_number BETWEEN 6 AND 10 THEN user_id ELSE NULL END) + 1)::FLOAT AS "6-10", 25 | COUNT(CASE WHEN event_number BETWEEN 11 AND 15 AND event_number < total_events THEN user_id ELSE NULL END)/ 26 | (COUNT(CASE WHEN event_number BETWEEN 11 AND 15 THEN user_id ELSE NULL END) + 1)::FLOAT AS "10-15", 27 | COUNT(CASE WHEN event_number BETWEEN 16 AND 20 AND event_number < total_events THEN user_id ELSE NULL END)/ 28 | (COUNT(CASE WHEN event_number BETWEEN 16 AND 20 THEN user_id ELSE NULL END) + 1)::FLOAT AS "16-20", 29 | COUNT(CASE WHEN event_number BETWEEN 21 AND 25 AND event_number < total_events THEN user_id ELSE NULL END)/ 30 | (COUNT(CASE WHEN event_number BETWEEN 21 AND 25 THEN user_id ELSE NULL END) + 1)::FLOAT AS "21-25", 31 | COUNT(CASE WHEN event_number BETWEEN 26 AND 30 AND event_number < total_events THEN user_id ELSE NULL END)/ 32 | (COUNT(CASE WHEN event_number BETWEEN 26 AND 30 THEN user_id ELSE NULL END) + 1)::FLOAT AS "26-30", 33 | COUNT(CASE WHEN event_number BETWEEN 31 AND 35 AND event_number < total_events THEN user_id ELSE NULL END)/ 34 | (COUNT(CASE WHEN event_number BETWEEN 31 AND 35 THEN user_id ELSE NULL END) + 1)::FLOAT AS "31-35", 35 | COUNT(CASE WHEN event_number BETWEEN 36 AND 40 AND event_number < total_events THEN user_id ELSE NULL END)/ 36 | (COUNT(CASE WHEN event_number BETWEEN 36 AND 40 THEN user_id ELSE NULL END) + 1)::FLOAT AS "36-40", 37 | COUNT(CASE WHEN event_number BETWEEN 41 AND 45 AND event_number < total_events THEN user_id ELSE NULL END)/ 38 | (COUNT(CASE WHEN event_number BETWEEN 41 AND 45 THEN user_id ELSE NULL END) + 1)::FLOAT AS "41-45", 39 | COUNT(CASE WHEN event_number BETWEEN 46 AND 50 AND event_number < total_events THEN user_id ELSE NULL END)/ 40 | (COUNT(CASE WHEN event_number BETWEEN 46 AND 50 THEN user_id ELSE NULL END) + 1)::FLOAT AS "46-50", 41 | COUNT(CASE WHEN event_number BETWEEN 51 AND 55 AND event_number < total_events THEN user_id ELSE NULL END)/ 42 | (COUNT(CASE WHEN event_number BETWEEN 51 AND 55 THEN user_id ELSE NULL END) + 1)::FLOAT AS "51-55", 43 | COUNT(CASE WHEN event_number BETWEEN 56 AND 60 AND event_number < total_events THEN user_id ELSE NULL END)/ 44 | (COUNT(CASE WHEN event_number BETWEEN 56 AND 60 THEN user_id ELSE NULL END) + 1)::FLOAT AS "56-60", 45 | COUNT(CASE WHEN event_number BETWEEN 61 AND 65 AND event_number < total_events THEN user_id ELSE NULL END)/ 46 | (COUNT(CASE WHEN event_number BETWEEN 61 AND 65 THEN user_id ELSE NULL END) + 1)::FLOAT AS "61-65", 47 | COUNT(CASE WHEN event_number BETWEEN 66 AND 70 AND event_number < total_events THEN user_id ELSE NULL END)/ 48 | (COUNT(CASE WHEN event_number BETWEEN 66 AND 70 THEN user_id ELSE NULL END) + 1)::FLOAT AS "66-70", 49 | COUNT(CASE WHEN event_number BETWEEN 71 AND 75 AND event_number < total_events THEN user_id ELSE NULL END)/ 50 | (COUNT(CASE WHEN event_number BETWEEN 71 AND 75 THEN user_id ELSE NULL END) + 1)::FLOAT AS "71-75" 51 | 52 | 53 | 54 | 55 | FROM ( 56 | 57 | SELECT c.counter AS days_since_last_event, 58 | x.* 59 | FROM (SELECT s.a AS counter FROM generate_series(0,100) AS s(a)) c 60 | LEFT JOIN ( 61 | SELECT e.user_id, 62 | e.occurred_at, 63 | EXTRACT('day' FROM NOW() - e.occurred_at) AS days_until_now, 64 | COUNT(*) OVER (PARTITION BY e.user_id) AS total_events, 65 | ROW_NUMBER() OVER (PARTITION BY e.user_id ORDER BY e.occurred_at) AS event_number, 66 | COALESCE( 67 | EXTRACT('DAY' FROM LEAD(e.occurred_at,1) OVER (PARTITION BY e.user_id ORDER BY e.occurred_at) - e.occurred_at), 68 | EXTRACT('DAY' FROM NOW() - e.occurred_at) 69 | ) AS days_until_next 70 | FROM events e 71 | ) x 72 | ON x.days_until_next > c.counter 73 | ) z 74 | WHERE days_until_now >= 30 75 | AND days_since_last_event <= 100 76 | AND event_number <= 75 77 | GROUP BY 1 78 | ORDER BY 1 -------------------------------------------------------------------------------- /retention_playbook/retention_cohorts/presentation.html: -------------------------------------------------------------------------------- 1 | 2 | 3 | 91 | 92 | 106 | 107 | 108 | 109 | -------------------------------------------------------------------------------- /retention_playbook/metrics_that_matter_p2/presentation.html: -------------------------------------------------------------------------------- 1 | 145 |Retention by Action in Users' First Week
146 | 147 |Filters
149 |150 | Show users who have taken each of these actions at least the chosen number of times. 151 |
152 | 153 |Table 1: Retention Percentage
116 |Periods after signup
117 | 118 | 119 |Table 2: Churn Rate
122 |Periods after signup
123 | 124 | 125 |Table 3: Churn Rate from Previous Period
128 |Periods after signup
129 | 130 | 131 |Event Sequences by Session
79 |Hover over bars in the circle for details
80 | 81 |Retention by Action in Users' First Week
132 |Showing
133 | 139 |141 | The bars below show the retention rates of users who took certain actions 142 | a minimun number of times. 143 |
144 |145 | These bars can show which features appear to drive retention. 146 |
147 | 151 | 155 | 159 | 164 | 170 | 175 |