|
| 1 | +WITH date_bounds AS ( |
| 2 | + SELECT |
| 3 | + DATE_TRUNC('day', CURRENT_TIMESTAMP) - INTERVAL '89 days' AS start_date, |
| 4 | + DATE_TRUNC('day', CURRENT_TIMESTAMP) + INTERVAL '1 day' AS end_date |
| 5 | +), |
| 6 | +new_members AS ( |
| 7 | + SELECT |
| 8 | + u.user_id, |
| 9 | + DATE_TRUNC('day', u.create_date)::date AS member_since_date |
| 10 | + FROM identity."user" u |
| 11 | + CROSS JOIN date_bounds db |
| 12 | + WHERE u.status ILIKE 'A' |
| 13 | + AND u.create_date IS NOT NULL |
| 14 | + AND u.create_date >= db.start_date |
| 15 | + AND u.create_date < db.end_date |
| 16 | +), |
| 17 | +member_activity AS ( |
| 18 | + SELECT |
| 19 | + nm.user_id, |
| 20 | + nm.member_since_date, |
| 21 | + EXISTS ( |
| 22 | + SELECT 1 |
| 23 | + FROM resources."Resource" r |
| 24 | + JOIN resources."ResourceRole" rr |
| 25 | + ON rr.id = r."roleId" |
| 26 | + JOIN challenges."Challenge" c |
| 27 | + ON c.id = r."challengeId" |
| 28 | + JOIN challenges."ChallengeTrack" ct |
| 29 | + ON ct.id = c."trackId" |
| 30 | + WHERE rr.name = 'Submitter' |
| 31 | + AND ct.track = 'DESIGN' |
| 32 | + AND r."memberId" = nm.user_id::text |
| 33 | + AND r."createdAt" >= nm.member_since_date |
| 34 | + AND r."createdAt" < nm.member_since_date + INTERVAL '90 days' |
| 35 | + ) AS design_participant, |
| 36 | + EXISTS ( |
| 37 | + SELECT 1 |
| 38 | + FROM reviews.submission s |
| 39 | + JOIN challenges."Challenge" c |
| 40 | + ON c.id = s."challengeId" |
| 41 | + JOIN challenges."ChallengeTrack" ct |
| 42 | + ON ct.id = c."trackId" |
| 43 | + WHERE s.status <> 'DELETED' |
| 44 | + AND ct.track = 'DESIGN' |
| 45 | + AND s."memberId" = nm.user_id::text |
| 46 | + AND COALESCE(s."submittedDate", s."createdAt") >= nm.member_since_date |
| 47 | + AND COALESCE(s."submittedDate", s."createdAt") < nm.member_since_date + INTERVAL '90 days' |
| 48 | + ) AS design_submitter, |
| 49 | + EXISTS ( |
| 50 | + SELECT 1 |
| 51 | + FROM resources."Resource" r |
| 52 | + JOIN resources."ResourceRole" rr |
| 53 | + ON rr.id = r."roleId" |
| 54 | + JOIN challenges."Challenge" c |
| 55 | + ON c.id = r."challengeId" |
| 56 | + JOIN challenges."ChallengeTrack" ct |
| 57 | + ON ct.id = c."trackId" |
| 58 | + WHERE rr.name = 'Submitter' |
| 59 | + AND ct.track IN ('DEVELOPMENT', 'DATA_SCIENCE') |
| 60 | + AND r."memberId" = nm.user_id::text |
| 61 | + AND r."createdAt" >= nm.member_since_date |
| 62 | + AND r."createdAt" < nm.member_since_date + INTERVAL '90 days' |
| 63 | + ) AS dev_participant, |
| 64 | + EXISTS ( |
| 65 | + SELECT 1 |
| 66 | + FROM reviews.submission s |
| 67 | + JOIN challenges."Challenge" c |
| 68 | + ON c.id = s."challengeId" |
| 69 | + JOIN challenges."ChallengeTrack" ct |
| 70 | + ON ct.id = c."trackId" |
| 71 | + WHERE s.status <> 'DELETED' |
| 72 | + AND ct.track IN ('DEVELOPMENT', 'DATA_SCIENCE') |
| 73 | + AND s."memberId" = nm.user_id::text |
| 74 | + AND COALESCE(s."submittedDate", s."createdAt") >= nm.member_since_date |
| 75 | + AND COALESCE(s."submittedDate", s."createdAt") < nm.member_since_date + INTERVAL '90 days' |
| 76 | + ) AS dev_submitter |
| 77 | + FROM new_members nm |
| 78 | +) |
| 79 | +SELECT |
| 80 | + COALESCE( |
| 81 | + MAX(EXTRACT(YEAR FROM ma.member_since_date))::integer, |
| 82 | + EXTRACT(YEAR FROM CURRENT_DATE)::integer |
| 83 | + ) AS "participant_funnel_monthly.member_since_date_year", |
| 84 | + COUNT(*) AS "participant_funnel_monthly.new_signups", |
| 85 | + COUNT(*) FILTER (WHERE ma.design_participant) AS "participant_funnel_monthly.new_design_participants", |
| 86 | + COUNT(*) FILTER (WHERE ma.design_submitter) AS "participant_funnel_monthly.new_design_submitters", |
| 87 | + COUNT(*) FILTER (WHERE ma.dev_participant) AS "participant_funnel_monthly.new_dev_participants", |
| 88 | + COUNT(*) FILTER (WHERE ma.dev_submitter) AS "participant_funnel_monthly.new_dev_submitters" |
| 89 | +FROM member_activity ma; |
0 commit comments