Skip to content

Commit 73b5f78

Browse files
committed
Additional stat reports
1 parent c43b8d5 commit 73b5f78

10 files changed

+1265
-0
lines changed
Lines changed: 66 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,66 @@
1+
WITH last_phase AS (
2+
SELECT
3+
ph."challengeId" AS challenge_id,
4+
MAX(COALESCE(ph."actualEndDate", ph."scheduledEndDate")) AS last_phase_end_dt
5+
FROM challenges."ChallengePhase" ph
6+
GROUP BY ph."challengeId"
7+
),
8+
completed_challenges AS (
9+
SELECT
10+
c.id AS challenge_id,
11+
COALESCE(c."startDate", c."registrationStartDate", c."createdAt") AS start_dt,
12+
COALESCE(
13+
lp.last_phase_end_dt,
14+
c."updatedAt",
15+
c."endDate",
16+
c."createdAt"
17+
) AS completion_dt,
18+
proj.name AS project_name,
19+
c.groups
20+
FROM challenges."Challenge" c
21+
LEFT JOIN last_phase lp
22+
ON lp.challenge_id = c.id
23+
LEFT JOIN projects.projects proj
24+
ON proj.id = c."projectId"::bigint
25+
WHERE c.status = 'COMPLETED'
26+
AND COALESCE(c."taskIsTask", false) = false
27+
AND (
28+
proj.name IS NULL
29+
OR (
30+
proj.name NOT ILIKE 'Fun & Learning Challenges (Jaipur)'
31+
AND proj.name NOT ILIKE 'Fun & Learning - 2016 (Jaipur)'
32+
AND proj.name NOT ILIKE 'TopGear Trial'
33+
)
34+
)
35+
AND NOT EXISTS (
36+
SELECT 1
37+
FROM unnest(COALESCE(c.groups, ARRAY[]::text[])) AS group_ref(group_id)
38+
JOIN groups."Group" g ON g.id = group_ref.group_id
39+
WHERE g.name ILIKE 'Wipro%'
40+
)
41+
AND COALESCE(
42+
lp.last_phase_end_dt,
43+
c."updatedAt",
44+
c."endDate",
45+
c."createdAt"
46+
) >= (DATE_TRUNC('day', CURRENT_TIMESTAMP) - INTERVAL '89 days')
47+
AND COALESCE(
48+
lp.last_phase_end_dt,
49+
c."updatedAt",
50+
c."endDate",
51+
c."createdAt"
52+
) < (DATE_TRUNC('day', CURRENT_TIMESTAMP) + INTERVAL '1 day')
53+
),
54+
durations AS (
55+
SELECT
56+
cc.challenge_id,
57+
GREATEST(
58+
EXTRACT(EPOCH FROM (cc.completion_dt - cc.start_dt)) / 3600.0,
59+
0
60+
) AS duration_hours
61+
FROM completed_challenges cc
62+
)
63+
SELECT
64+
COALESCE(SUM(durations.duration_hours), 0)::numeric(18, 2) AS "challenge.duration",
65+
COUNT(*)::bigint AS "challenge.count"
66+
FROM durations;
Lines changed: 89 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,89 @@
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;
Lines changed: 83 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,83 @@
1+
WITH week_bounds AS (
2+
SELECT
3+
(DATE_TRUNC('week', CURRENT_DATE + INTERVAL '1 day') - INTERVAL '1 day')::date AS current_week_start
4+
),
5+
new_members AS (
6+
SELECT
7+
u.user_id,
8+
DATE(u.create_date) AS member_since_date
9+
FROM identity."user" u
10+
CROSS JOIN week_bounds wb
11+
WHERE u.create_date IS NOT NULL
12+
AND u.status ILIKE 'A'
13+
AND DATE(u.create_date) >= wb.current_week_start - INTERVAL '4 weeks'
14+
AND DATE(u.create_date) < wb.current_week_start
15+
),
16+
registrant_activity AS (
17+
SELECT DISTINCT
18+
r."memberId" AS member_id,
19+
ct.track
20+
FROM resources."Resource" r
21+
JOIN resources."ResourceRole" rr
22+
ON rr.id = r."roleId"
23+
JOIN challenges."Challenge" c
24+
ON c.id = r."challengeId"
25+
JOIN challenges."ChallengeTrack" ct
26+
ON ct.id = c."trackId"
27+
WHERE COALESCE(rr."nameLower", LOWER(rr.name)) = 'submitter'
28+
),
29+
submission_activity AS (
30+
SELECT DISTINCT
31+
s."memberId" AS member_id,
32+
ct.track
33+
FROM reviews.submission s
34+
JOIN challenges."Challenge" c
35+
ON c.id = s."challengeId"
36+
JOIN challenges."ChallengeTrack" ct
37+
ON ct.id = c."trackId"
38+
WHERE s.status <> 'DELETED'
39+
),
40+
member_funnel AS (
41+
SELECT
42+
nm.user_id,
43+
nm.member_since_date,
44+
EXISTS (
45+
SELECT 1
46+
FROM registrant_activity ra
47+
WHERE ra.member_id = nm.user_id::text
48+
AND ra.track = 'DESIGN'
49+
) AS design_participant,
50+
EXISTS (
51+
SELECT 1
52+
FROM submission_activity sa
53+
WHERE sa.member_id = nm.user_id::text
54+
AND sa.track = 'DESIGN'
55+
) AS design_submitter,
56+
EXISTS (
57+
SELECT 1
58+
FROM registrant_activity ra
59+
WHERE ra.member_id = nm.user_id::text
60+
AND ra.track IN ('DEVELOPMENT', 'DATA_SCIENCE', 'QUALITY_ASSURANCE')
61+
) AS dev_participant,
62+
EXISTS (
63+
SELECT 1
64+
FROM submission_activity sa
65+
WHERE sa.member_id = nm.user_id::text
66+
AND sa.track IN ('DEVELOPMENT', 'DATA_SCIENCE', 'QUALITY_ASSURANCE')
67+
) AS dev_submitter
68+
FROM new_members nm
69+
)
70+
SELECT
71+
TO_CHAR(
72+
DATE_TRUNC('week', mf.member_since_date + INTERVAL '1 day') - INTERVAL '1 day',
73+
'YYYY-MM-DD'
74+
) AS "participant_funnel_monthly.member_since_date_week",
75+
COUNT(*) AS "participant_funnel_monthly.new_signups",
76+
COUNT(*) FILTER (WHERE mf.design_participant) AS "participant_funnel_monthly.new_design_participants",
77+
COUNT(*) FILTER (WHERE mf.design_submitter) AS "participant_funnel_monthly.new_design_submitters",
78+
COUNT(*) FILTER (WHERE mf.dev_participant) AS "participant_funnel_monthly.new_dev_participants",
79+
COUNT(*) FILTER (WHERE mf.dev_submitter) AS "participant_funnel_monthly.new_dev_submitters"
80+
FROM member_funnel mf
81+
GROUP BY 1
82+
ORDER BY 1 DESC
83+
LIMIT 500;

0 commit comments

Comments
 (0)