SELECT | |
sum(view_homepage) AS viewed_homepage, | |
sum(use_demo) AS use_demo, | |
sum(enter_credit_card) AS entered_credit_card | |
FROM ( | |
-- Get the first time each user viewed the homepage. | |
SELECT | |
user_id, | |
1 AS view_homepage, | |
min(time) AS view_homepage_time | |
FROM event | |
WHERE | |
data->>'type' = 'view_homepage' | |
GROUP BY user_id | |
) e1 LEFT JOIN LATERAL ( | |
-- For each row, get the first time the user_id did the use_demo | |
-- event, if one exists within one week of view_homepage_time. | |
SELECT | |
user_id, | |
1 AS use_demo, | |
time AS use_demo_time | |
FROM event | |
WHERE | |
user_id = e1.user_id AND | |
data->>'type' = 'use_demo' AND | |
time BETWEEN view_homepage_time AND (view_homepage_time + 1000*60*60*24*7) | |
ORDER BY time | |
LIMIT 1 | |
) e2 ON true LEFT JOIN LATERAL ( | |
-- For each row, get the first time the user_id did the enter_credit_card | |
-- event, if one exists within one week of use_demo_time. | |
SELECT | |
1 AS enter_credit_card, | |
time AS enter_credit_card_time | |
FROM event | |
WHERE | |
user_id = e2.user_id AND | |
data->>'type' = 'enter_credit_card' AND | |
time BETWEEN use_demo_time AND (use_demo_time + 1000*60*60*24*7) | |
ORDER BY time | |
LIMIT 1 | |
) e3 ON true |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment