-- First establish some base parameters for our users WITH config AS ( SELECT 14 AS short_term, 90 AS medium_term, 360 AS long_term, CAST('2023-01-01' AS timestamp) AS date_cutoff ), -- Then establish a standard core set of user data users_with_churn_stats AS ( SELECT id, active, billing_state, DATE_TRUNC('month', created_at) AS month_created, created_at, free_trial_ends_at, updated_at, updated_at::date - created_at::date AS lifespan FROM users, config -- We'll only look at newish users. WHERE created_at >= config.date_cutoff ), -- Next use that core data to extract the records we want to analyze -- and categorize them by date and status users_to_examine AS ( -- First the users who exited just after the trial SELECT 'quick-exit' AS category, uwcs.* FROM users_with_churn_stats uwcs, config WHERE billing_state = 'CHURNED' AND lifespan <= config.short_term UNION -- Next, users who gave the tools some time but still left SELECT 'fair-trial' AS category, uwcs.* FROM users_with_churn_stats uwcs, config WHERE billing_state = 'CHURNED' AND lifespan < config.medium_term AND lifespan > config.short_term UNION -- Then some longer-time users who still churned. -- We'll cut this off after 6 months since afterwards -- company closures, etc. could factor in. SELECT 'short-termer' AS category, uwcs.* FROM users_with_churn_stats uwcs, config WHERE billing_state = 'CHURNED' AND lifespan >= config.medium_term AND lifespan < config.long_term UNION -- Finally, people who are still kicking. -- This cohort is going to be a little wrong for older -- dates since it only includes those who are STILL around. SELECT 'active-user' AS category, uwcs.* FROM users_with_churn_stats uwcs, config WHERE BILLING_STATE != 'CHURNED' AND lifespan >= config.long_term ), -- Emails sent by era email_counts AS ( SELECT email.user_id, SUM(CASE WHEN created_age < config.short_term THEN 1 ELSE 0 END) AS short_term, SUM(CASE WHEN created_age >= config.short_term AND created_age < config.medium_term THEN 1 ELSE 0 END) AS medium_term, SUM(CASE WHEN created_age >= config.medium_term AND created_age < config.long_term THEN 1 ELSE 0 END) AS long_term, COUNT(*) AS total FROM config, ( SELECT sent_emails.user_id, sent_emails.created_at::date - users.created_at::date AS created_age FROM config, sent_emails JOIN users ON sent_emails.user_id = users.id WHERE sent_emails.created_at >= config.date_cutoff AND users.created_at >= config.date_cutoff ) email GROUP BY email.user_id ) -- Finally, we'll flatten it all out into a repurposable flat table SELECT users_to_examine.id, users_to_examine.category, COALESCE(email_counts.short_term, 0) AS emails_short_term, COALESCE(email_counts.medium_term, 0) AS emails_medium_term, COALESCE(email_counts.long_term, 0) AS emails_long_term, COALESCE(email_counts.total, 0) AS emails FROM users_to_examine LEFT OUTER JOIN email_counts ON email_counts.user_id = users_to_examine.id ;