Skip to content

Commit c43b8d5

Browse files
committed
New report endpoints for Looker dashboard replacement
1 parent ce63d51 commit c43b8d5

21 files changed

+800
-16
lines changed
Lines changed: 63 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,63 @@
1+
WITH challenge_window AS (
2+
SELECT
3+
c.id,
4+
c."projectId" AS project_id,
5+
COALESCE(
6+
c."registrationStartDate",
7+
c."startDate",
8+
c."createdAt"
9+
) AS posting_dt
10+
FROM challenges."Challenge" c
11+
WHERE COALESCE(
12+
c."registrationStartDate",
13+
c."startDate",
14+
c."createdAt"
15+
) >= (DATE_TRUNC('day', CURRENT_TIMESTAMP) - INTERVAL '89 days')
16+
AND COALESCE(
17+
c."registrationStartDate",
18+
c."startDate",
19+
c."createdAt"
20+
) < (DATE_TRUNC('day', CURRENT_TIMESTAMP) + INTERVAL '1 day')
21+
AND (
22+
c.status IS NULL
23+
OR c.status NOT IN ('DELETED', 'DRAFT', 'NEW')
24+
)
25+
AND NOT EXISTS (
26+
SELECT 1
27+
FROM unnest(COALESCE(c.groups, ARRAY[]::text[])) AS group_ref(group_id)
28+
JOIN groups."Group" g
29+
ON g.id = group_ref.group_id
30+
WHERE g.name ILIKE 'Wipro%'
31+
)
32+
)
33+
SELECT
34+
COUNT(DISTINCT r."memberId")::bigint AS "copilot.count"
35+
FROM challenge_window cw
36+
JOIN resources."Resource" r
37+
ON r."challengeId" = cw.id
38+
JOIN resources."ResourceRole" rr
39+
ON rr.id = r."roleId"
40+
LEFT JOIN members.member m
41+
ON m."userId"::text = r."memberId"
42+
LEFT JOIN projects.projects proj
43+
ON proj.id = cw.project_id::bigint
44+
WHERE COALESCE(rr."nameLower", LOWER(rr.name)) = 'copilot'
45+
AND (
46+
proj.name IS NULL
47+
OR (
48+
proj.name NOT ILIKE 'Fun & Learning Challenges (Jaipur)'
49+
AND proj.name NOT ILIKE 'Fun & Learning - 2016 (Jaipur)'
50+
AND proj.name NOT ILIKE 'TopGear Trial'
51+
)
52+
)
53+
AND (
54+
m.email IS NULL
55+
OR (
56+
m.email NOT ILIKE '%@topcoder.com'
57+
AND m.email NOT ILIKE '%@wipro.com'
58+
)
59+
)
60+
AND COALESCE(
61+
NULLIF(TRIM(m.handle), ''),
62+
NULLIF(TRIM(r."memberHandle"), '')
63+
) IS NOT NULL;
Lines changed: 65 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,65 @@
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+
eligible_challenges AS (
9+
SELECT
10+
c.id AS challenge_id,
11+
COALESCE(lp.last_phase_end_dt, c."updatedAt", c."endDate", c."createdAt") AS completion_dt
12+
FROM challenges."Challenge" c
13+
LEFT JOIN last_phase lp
14+
ON lp.challenge_id = c.id
15+
LEFT JOIN projects.projects proj
16+
ON proj.id = c."projectId"::bigint
17+
WHERE c.status = 'COMPLETED'
18+
AND COALESCE(c."taskIsTask", false) = false
19+
AND (
20+
proj.name IS NULL
21+
OR (
22+
proj.name NOT ILIKE 'Fun & Learning Challenges (Jaipur)'
23+
AND proj.name NOT ILIKE 'Fun & Learning - 2016 (Jaipur)'
24+
AND proj.name NOT ILIKE 'TopGear Trial'
25+
)
26+
)
27+
AND NOT EXISTS (
28+
SELECT 1
29+
FROM unnest(COALESCE(c.groups, ARRAY[]::text[])) AS group_ref(group_id)
30+
JOIN groups."Group" g ON g.id = group_ref.group_id
31+
WHERE g.name ILIKE 'Wipro%'
32+
)
33+
AND COALESCE(lp.last_phase_end_dt, c."updatedAt", c."endDate", c."createdAt") >= (DATE_TRUNC('day', CURRENT_TIMESTAMP) - INTERVAL '89 days')
34+
AND COALESCE(lp.last_phase_end_dt, c."updatedAt", c."endDate", c."createdAt") < (DATE_TRUNC('day', CURRENT_TIMESTAMP) + INTERVAL '1 day')
35+
),
36+
challenge_payments AS (
37+
SELECT DISTINCT
38+
p.payment_id,
39+
w.external_id AS challenge_id,
40+
p.gross_amount
41+
FROM finance.payment p
42+
JOIN finance.winnings w
43+
ON w.winning_id = p.winnings_id
44+
JOIN eligible_challenges ec
45+
ON ec.challenge_id = w.external_id
46+
WHERE (p.payment_status IS NULL OR p.payment_status != 'CANCELLED')
47+
AND p.gross_amount IS NOT NULL
48+
),
49+
aggregated AS (
50+
SELECT
51+
COALESCE(SUM(cp.gross_amount), 0)::numeric(18, 2) AS total_member_payments,
52+
COUNT(cp.payment_id) AS payment_count,
53+
COUNT(DISTINCT cp.challenge_id) AS challenge_count
54+
FROM challenge_payments cp
55+
)
56+
SELECT
57+
(
58+
CASE
59+
WHEN aggregated.payment_count = 0 THEN 0::numeric
60+
ELSE ROUND(aggregated.total_member_payments / aggregated.payment_count::numeric, 2)
61+
END
62+
)::numeric(18, 2) AS "cost_transaction.average_member_payments",
63+
COALESCE(aggregated.total_member_payments, 0)::numeric(18, 2) AS "cost_transaction.member_payments",
64+
COALESCE(aggregated.challenge_count, 0)::bigint AS "cost_transaction.count_challenges"
65+
FROM aggregated;
Lines changed: 70 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,70 @@
1+
WITH billing AS (
2+
SELECT
3+
c.id AS challenge_id,
4+
COALESCE(
5+
MAX(ba.name) FILTER (WHERE ba.name IS NOT NULL),
6+
MAX(project_ba.name) FILTER (WHERE project_ba.name IS NOT NULL)
7+
) AS billing_account_name
8+
FROM challenges."Challenge" c
9+
LEFT JOIN challenges."ChallengeBilling" cb
10+
ON cb."challengeId" = c.id
11+
LEFT JOIN "billing-accounts"."BillingAccount" ba
12+
ON ba.id = NULLIF(cb."billingAccountId", '')::bigint
13+
LEFT JOIN projects.projects proj
14+
ON proj.id = c."projectId"::bigint
15+
LEFT JOIN "billing-accounts"."BillingAccount" project_ba
16+
ON project_ba.id = proj."billingAccountId"
17+
GROUP BY c.id
18+
),
19+
filtered_challenges AS (
20+
SELECT
21+
c.id AS challenge_id
22+
FROM challenges."Challenge" c
23+
LEFT JOIN billing bill
24+
ON bill.challenge_id = c.id
25+
WHERE (
26+
(
27+
bill.billing_account_name NOT ILIKE 'Fun & Learning Challenges (Jaipur)'
28+
AND bill.billing_account_name NOT ILIKE 'Fun & Learning - 2016 (Jaipur)'
29+
AND bill.billing_account_name NOT ILIKE 'TopGear Trial'
30+
)
31+
OR bill.billing_account_name IS NULL
32+
)
33+
AND NOT EXISTS (
34+
SELECT 1
35+
FROM unnest(COALESCE(c.groups, ARRAY[]::text[])) AS group_ref(group_id)
36+
JOIN groups."Group" g ON g.id = group_ref.group_id
37+
WHERE g.name ILIKE 'Wipro%'
38+
)
39+
),
40+
registrants AS (
41+
SELECT
42+
r."challengeId" AS challenge_id,
43+
r."memberId"::bigint AS member_id,
44+
COALESCE(NULLIF(r."memberHandle", ''), m.handle) AS member_handle,
45+
r."createdAt" AS registered_at
46+
FROM resources."Resource" r
47+
JOIN resources."ResourceRole" rr
48+
ON rr.id = r."roleId" AND rr.name = 'Submitter'
49+
LEFT JOIN members.member m
50+
ON m."userId" = r."memberId"::bigint
51+
WHERE r."createdAt" >= (CURRENT_DATE - INTERVAL '89 days')
52+
AND r."createdAt" < (CURRENT_DATE + INTERVAL '1 day')
53+
AND COALESCE(NULLIF(r."memberHandle", ''), m.handle) IS NOT NULL
54+
),
55+
submissions AS (
56+
SELECT DISTINCT
57+
s."challengeId" AS challenge_id,
58+
s."memberId"::bigint AS member_id
59+
FROM reviews.submission s
60+
WHERE s.status <> 'DELETED'
61+
)
62+
SELECT
63+
COUNT(DISTINCT reg.member_handle) AS "challenge_stats.count_distinct_registrant",
64+
COUNT(DISTINCT CASE WHEN sub.member_id IS NOT NULL THEN reg.member_handle END) AS "challenge_stats.count_distinct_submitter"
65+
FROM registrants reg
66+
JOIN filtered_challenges fc
67+
ON fc.challenge_id = reg.challenge_id
68+
LEFT JOIN submissions sub
69+
ON sub.challenge_id = reg.challenge_id
70+
AND sub.member_id = reg.member_id;
Lines changed: 48 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,48 @@
1+
WITH registrants AS (
2+
SELECT
3+
r."memberHandle" AS registrant_handle,
4+
r."memberId",
5+
r."challengeId",
6+
c.groups,
7+
ba.name AS billing_account_name
8+
FROM resources."Resource" AS r
9+
JOIN resources."ResourceRole" AS rr
10+
ON rr.id = r."roleId"
11+
JOIN challenges."Challenge" AS c
12+
ON c.id = r."challengeId"
13+
LEFT JOIN challenges."ChallengeBilling" AS cb
14+
ON cb."challengeId" = r."challengeId"
15+
LEFT JOIN "billing-accounts"."BillingAccount" AS ba
16+
ON ba.id::text = cb."billingAccountId"
17+
WHERE LOWER(rr.name) = 'submitter'
18+
AND r."createdAt" >= (DATE_TRUNC('day', CURRENT_TIMESTAMP) - INTERVAL '89 days')
19+
AND r."createdAt" < (DATE_TRUNC('day', CURRENT_TIMESTAMP) + INTERVAL '1 day')
20+
AND NOT EXISTS (
21+
SELECT 1
22+
FROM UNNEST(COALESCE(c.groups, ARRAY[]::text[])) AS group_ref(group_id)
23+
JOIN groups."Group" AS g
24+
ON g.id = group_ref.group_id
25+
WHERE g.name ILIKE 'Wipro%'
26+
)
27+
AND (
28+
ba.name IS NULL OR (
29+
ba.name NOT ILIKE 'Fun & Learning Challenges (Jaipur)'
30+
AND ba.name NOT ILIKE 'Fun & Learning - 2016 (Jaipur)'
31+
AND ba.name NOT ILIKE 'TopGear Trial'
32+
)
33+
)
34+
)
35+
SELECT
36+
COUNT(DISTINCT registrants.registrant_handle)::bigint AS "challenge_stats.count_distinct_registrant",
37+
COUNT(
38+
DISTINCT CASE
39+
WHEN EXISTS (
40+
SELECT 1
41+
FROM reviews.submission AS s
42+
WHERE s."challengeId" = registrants."challengeId"
43+
AND s."memberId" = registrants."memberId"
44+
)
45+
THEN registrants.registrant_handle
46+
END
47+
)::bigint AS "challenge_stats.count_distinct_submitter"
48+
FROM registrants;
Lines changed: 32 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,32 @@
1+
WITH launch_dates AS (
2+
SELECT
3+
c.id AS challenge_id,
4+
COALESCE(c."startDate", c."registrationStartDate", c."createdAt") AS launch_date,
5+
proj.name AS project_name,
6+
c.groups
7+
FROM challenges."Challenge" c
8+
LEFT JOIN projects.projects proj
9+
ON proj.id = c."projectId"::bigint
10+
WHERE COALESCE(c."taskIsTask", false) = false
11+
AND c.status NOT IN ('DRAFT', 'DELETED')
12+
AND c.status::text NOT ILIKE 'CANCELLED%'
13+
)
14+
SELECT
15+
COUNT(DISTINCT ld.challenge_id)::bigint AS "challenge.count"
16+
FROM launch_dates ld
17+
WHERE ld.launch_date >= (DATE_TRUNC('day', CURRENT_TIMESTAMP) - INTERVAL '89 days')
18+
AND ld.launch_date < (DATE_TRUNC('day', CURRENT_TIMESTAMP) + INTERVAL '1 day')
19+
AND (
20+
ld.project_name IS NULL
21+
OR (
22+
ld.project_name NOT ILIKE 'Fun & Learning Challenges (Jaipur)'
23+
AND ld.project_name NOT ILIKE 'Fun & Learning - 2016 (Jaipur)'
24+
AND ld.project_name NOT ILIKE 'TopGear Trial'
25+
)
26+
)
27+
AND NOT EXISTS (
28+
SELECT 1
29+
FROM unnest(COALESCE(ld.groups, ARRAY[]::text[])) AS group_ref(group_id)
30+
JOIN groups."Group" g ON g.id = group_ref.group_id
31+
WHERE g.name ILIKE 'Wipro%'
32+
);
Lines changed: 73 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,73 @@
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+
filtered_challenges AS (
9+
SELECT
10+
c.id AS challenge_id,
11+
c.status,
12+
COALESCE(lp.last_phase_end_dt, c."updatedAt", c."endDate", c."createdAt") AS activity_dt
13+
FROM challenges."Challenge" c
14+
LEFT JOIN last_phase lp
15+
ON lp.challenge_id = c.id
16+
LEFT JOIN projects.projects proj
17+
ON proj.id = c."projectId"::bigint
18+
WHERE c.status IN (
19+
'COMPLETED',
20+
'CANCELLED',
21+
'CANCELLED_FAILED_REVIEW',
22+
'CANCELLED_FAILED_SCREENING',
23+
'CANCELLED_ZERO_SUBMISSIONS',
24+
'CANCELLED_WINNER_UNRESPONSIVE',
25+
'CANCELLED_CLIENT_REQUEST',
26+
'CANCELLED_REQUIREMENTS_INFEASIBLE',
27+
'CANCELLED_ZERO_REGISTRATIONS',
28+
'CANCELLED_PAYMENT_FAILED'
29+
)
30+
AND (
31+
proj.name IS NULL
32+
OR (
33+
proj.name NOT ILIKE 'Fun & Learning Challenges (Jaipur)'
34+
AND proj.name NOT ILIKE 'Fun & Learning - 2016 (Jaipur)'
35+
AND proj.name NOT ILIKE 'TopGear Trial'
36+
)
37+
)
38+
AND NOT EXISTS (
39+
SELECT 1
40+
FROM unnest(COALESCE(c.groups, ARRAY[]::text[])) AS group_ref(group_id)
41+
JOIN groups."Group" g ON g.id = group_ref.group_id
42+
WHERE g.name ILIKE 'Wipro%'
43+
)
44+
AND COALESCE(lp.last_phase_end_dt, c."updatedAt", c."endDate", c."createdAt") >= (DATE_TRUNC('day', CURRENT_TIMESTAMP) - INTERVAL '89 days')
45+
AND COALESCE(lp.last_phase_end_dt, c."updatedAt", c."endDate", c."createdAt") < (DATE_TRUNC('day', CURRENT_TIMESTAMP) + INTERVAL '1 day')
46+
)
47+
SELECT
48+
CASE
49+
WHEN (counts.completed_challenges + counts.cancelled_challenges) = 0 THEN 0::numeric
50+
ELSE ROUND(
51+
counts.completed_challenges::numeric
52+
/ (counts.completed_challenges + counts.cancelled_challenges),
53+
4
54+
)
55+
END AS "challenge.fulfillment"
56+
FROM (
57+
SELECT
58+
COUNT(*) FILTER (WHERE status = 'COMPLETED') AS completed_challenges,
59+
COUNT(*) FILTER (
60+
WHERE status IN (
61+
'CANCELLED',
62+
'CANCELLED_FAILED_REVIEW',
63+
'CANCELLED_FAILED_SCREENING',
64+
'CANCELLED_ZERO_SUBMISSIONS',
65+
'CANCELLED_WINNER_UNRESPONSIVE',
66+
'CANCELLED_CLIENT_REQUEST',
67+
'CANCELLED_REQUIREMENTS_INFEASIBLE',
68+
'CANCELLED_ZERO_REGISTRATIONS',
69+
'CANCELLED_PAYMENT_FAILED'
70+
)
71+
) AS cancelled_challenges
72+
FROM filtered_challenges
73+
) AS counts;

0 commit comments

Comments
 (0)