147 lines
6.8 KiB
SQL
147 lines
6.8 KiB
SQL
-- 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
|
|
),
|
|
-- Well add booking forms created by era
|
|
booking_form_counts AS (
|
|
SELECT bf.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 booking_forms.user_id, booking_forms.created_at::date - users.created_at::date AS created_age
|
|
FROM config, booking_forms JOIN users ON booking_forms.user_id = users.id
|
|
WHERE booking_forms.created_at >= config.date_cutoff
|
|
AND users.created_at >= config.date_cutoff
|
|
) bf
|
|
GROUP BY bf.user_id
|
|
),
|
|
-- Bookings made by era
|
|
booking_counts AS (
|
|
SELECT bk.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 booking_forms.user_id, bookings.created_at::date - users.created_at::date AS created_age
|
|
FROM config, booking_forms
|
|
JOIN users ON booking_forms.user_id = users.id
|
|
JOIN bookings ON bookings.booking_form_id = booking_forms.id
|
|
WHERE booking_forms.created_at >= config.date_cutoff
|
|
AND bookings.created_at >= config.date_cutoff
|
|
AND users.created_at >= config.date_cutoff
|
|
) bk
|
|
GROUP BY bk.user_id
|
|
),
|
|
-- Employees added by era
|
|
employee_counts AS (
|
|
SELECT empl.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 employees.user_id, employees.created_at::date - users.created_at::date AS created_age
|
|
FROM config, employees JOIN users ON employees.user_id = users.id
|
|
WHERE employees.created_at >= config.date_cutoff
|
|
AND users.created_at >= config.date_cutoff
|
|
) empl
|
|
GROUP BY empl.user_id
|
|
),
|
|
-- Contacts created by era
|
|
contact_counts AS (
|
|
SELECT cust.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 customers.user_id, customers.created_at::date - users.created_at::date AS created_age
|
|
FROM config, customers JOIN users ON customers.user_id = users.id
|
|
WHERE customers.created_at >= config.date_cutoff
|
|
AND users.created_at >= config.date_cutoff
|
|
) cust
|
|
GROUP BY cust.user_id
|
|
),
|
|
-- Finally, we'll flatten it all out into a repurposable flat table
|
|
SELECT users_to_examine.id,
|
|
users_to_examine.category,
|
|
COALESCE(booking_form_counts.short_term, 0) AS booking_forms_short_term,
|
|
COALESCE(booking_form_counts.medium_term, 0) AS booking_forms_medium_term,
|
|
COALESCE(booking_form_counts.long_term, 0) AS booking_forms_long_term,
|
|
COALESCE(booking_form_counts.total, 0) AS booking_forms,
|
|
COALESCE(booking_counts.short_term, 0) AS bookings_short_term,
|
|
COALESCE(booking_counts.medium_term, 0) AS bookings_medium_term,
|
|
COALESCE(booking_counts.long_term, 0) AS bookings_long_term,
|
|
COALESCE(booking_counts.total, 0) AS bookings,
|
|
COALESCE(employee_counts.short_term, 0) AS employees_short_term,
|
|
COALESCE(employee_counts.medium_term, 0) AS employees_medium_term,
|
|
COALESCE(employee_counts.long_term, 0) AS employees_long_term,
|
|
COALESCE(employee_counts.total, 0) AS employees,
|
|
COALESCE(contact_counts.short_term, 0) AS contacts_short_term,
|
|
COALESCE(contact_counts.medium_term, 0) AS contacts_medium_term,
|
|
COALESCE(contact_counts.long_term, 0) AS contacts_long_term,
|
|
COALESCE(contact_counts.total, 0) AS contacts
|
|
FROM users_to_examine
|
|
LEFT OUTER JOIN booking_form_counts ON booking_form_counts.user_id = users_to_examine.id
|
|
LEFT OUTER JOIN booking_counts ON booking_counts.user_id = users_to_examine.id
|
|
LEFT OUTER JOIN employee_counts ON employee_counts.user_id = users_to_examine.id
|
|
LEFT OUTER JOIN contact_counts ON contact_counts.user_id = users_to_examine.id
|
|
;
|