152 lines
7.2 KiB
SQL
152 lines
7.2 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
|
|
),
|
|
-- Messages sent by era
|
|
sms_counts AS (
|
|
SELECT texts.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_texts.user_id, sent_texts.created_at::date - users.created_at::date AS created_age
|
|
FROM config, sent_texts JOIN users ON sent_texts.user_id = users.id
|
|
WHERE sent_texts.created_at >= config.date_cutoff
|
|
AND users.created_at >= config.date_cutoff
|
|
) texts
|
|
GROUP BY texts.user_id
|
|
),
|
|
-- Appointments by era
|
|
appointment_counts AS (
|
|
SELECT appts.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 appointments.user_id, appointments.created_at::date - users.created_at::date AS created_age
|
|
FROM config, appointments JOIN users ON appointments.user_id = users.id
|
|
WHERE appointments.created_at >= config.date_cutoff
|
|
AND users.created_at >= config.date_cutoff
|
|
) appts
|
|
GROUP BY appts.user_id
|
|
),
|
|
-- Checklists created by era
|
|
checklist_counts AS (
|
|
SELECT checks.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 checklist_templates.user_id, checklists.created_at::date - users.created_at::date AS created_age
|
|
FROM config, checklist_templates
|
|
JOIN users ON checklist_templates.user_id = users.id
|
|
JOIN checklists ON checklists.checklist_template_id = checklist_templates.id
|
|
WHERE checklist_templates.created_at >= config.date_cutoff
|
|
AND checklists.created_at >= config.date_cutoff
|
|
AND users.created_at >= config.date_cutoff
|
|
) checks
|
|
GROUP BY checks.user_id
|
|
),
|
|
-- Checklist events created by era
|
|
checklist_filled_counts AS (
|
|
SELECT events.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, checklist_item_events.created_at::date - users.created_at::date AS created_age
|
|
FROM config, employees
|
|
JOIN users ON employees.user_id = users.id
|
|
JOIN checklist_item_events ON checklist_item_events.employee_id = employees.id
|
|
WHERE checklist_item_events.created_at >= config.date_cutoff
|
|
AND checklist_item_events.created_at >= config.date_cutoff
|
|
AND users.created_at >= config.date_cutoff
|
|
) events
|
|
GROUP BY events.user_id
|
|
)
|
|
-- Finally, we'll flatten it all out into a repurposable flat table
|
|
SELECT users_to_examine.id,
|
|
users_to_examine.category,
|
|
users_to_examine.month_created,
|
|
users_to_examine.lifespan,
|
|
COALESCE(sms_counts.short_term, 0) AS sms_short_term,
|
|
COALESCE(sms_counts.medium_term, 0) AS sms_medium_term,
|
|
COALESCE(sms_counts.long_term, 0) AS sms_long_term,
|
|
COALESCE(sms_counts.total, 0) AS sms,
|
|
COALESCE(appointment_counts.short_term, 0) AS appointments_short_term,
|
|
COALESCE(appointment_counts.medium_term, 0) AS appointments_medium_term,
|
|
COALESCE(appointment_counts.long_term, 0) AS appointments_long_term,
|
|
COALESCE(appointment_counts.total, 0) AS appointments,
|
|
COALESCE(checklist_counts.short_term, 0) AS checklists_short_term,
|
|
COALESCE(checklist_counts.medium_term, 0) AS checklists_medium_term,
|
|
COALESCE(checklist_counts.long_term, 0) AS checklists_long_term,
|
|
COALESCE(checklist_counts.total, 0) AS checklists,
|
|
COALESCE(checklist_filled_counts.short_term, 0) AS checklists_filled_short_term,
|
|
COALESCE(checklist_filled_counts.medium_term, 0) AS checklists_filled_medium_term,
|
|
COALESCE(checklist_filled_counts.long_term, 0) AS checklists_filled_long_term,
|
|
COALESCE(checklist_filled_counts.total, 0) AS checklists_filled
|
|
FROM users_to_examine
|
|
LEFT OUTER JOIN sms_counts ON sms_counts.user_id = users_to_examine.id
|
|
LEFT OUTER JOIN appointment_counts ON appointment_counts.user_id = users_to_examine.id
|
|
LEFT OUTER JOIN checklist_counts ON checklist_counts.user_id = users_to_examine.id
|
|
LEFT OUTER JOIN checklist_filled_counts ON checklist_filled_counts.user_id = users_to_examine.id
|
|
;
|