|
| 1 | +WITH typed_challenges AS ( |
| 2 | + SELECT |
| 3 | + c.id, |
| 4 | + c.name |
| 5 | + FROM challenges."Challenge" AS c |
| 6 | + WHERE c."typeId" = '929bc408-9cf2-4b3e-ba71-adfbf693046c' |
| 7 | +), |
| 8 | +submission_participants AS ( |
| 9 | + SELECT DISTINCT ON (s."memberId", tc.id) |
| 10 | + s."memberId"::bigint AS member_id, |
| 11 | + COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) AS member_handle, |
| 12 | + tc.id AS challenge_id, |
| 13 | + s.placement |
| 14 | + FROM typed_challenges AS tc |
| 15 | + JOIN reviews."submission" AS s |
| 16 | + ON s."challengeId" = tc.id |
| 17 | + LEFT JOIN members."member" AS m |
| 18 | + ON m."userId" = s."memberId"::bigint |
| 19 | + ORDER BY |
| 20 | + s."memberId", |
| 21 | + tc.id, |
| 22 | + s.placement NULLS FIRST, |
| 23 | + s.id DESC |
| 24 | +), |
| 25 | +winner_participants AS ( |
| 26 | + SELECT DISTINCT ON (cw."userId", tc.id) |
| 27 | + cw."userId"::bigint AS member_id, |
| 28 | + COALESCE( |
| 29 | + NULLIF(TRIM(cw.handle), ''), |
| 30 | + NULLIF(TRIM(m.handle), ''), |
| 31 | + m.handle |
| 32 | + ) AS member_handle, |
| 33 | + tc.id AS challenge_id, |
| 34 | + cw.placement |
| 35 | + FROM typed_challenges AS tc |
| 36 | + JOIN challenges."ChallengeWinner" AS cw |
| 37 | + ON cw."challengeId" = tc.id |
| 38 | + LEFT JOIN members."member" AS m |
| 39 | + ON m."userId" = cw."userId"::bigint |
| 40 | + ORDER BY |
| 41 | + cw."userId", |
| 42 | + tc.id, |
| 43 | + cw.placement NULLS FIRST, |
| 44 | + cw.id DESC |
| 45 | +), |
| 46 | +combined_participants AS ( |
| 47 | + SELECT |
| 48 | + COALESCE(wp.member_id, sp.member_id) AS member_id, |
| 49 | + COALESCE(wp.member_handle, sp.member_handle) AS member_handle, |
| 50 | + COALESCE(wp.challenge_id, sp.challenge_id) AS challenge_id, |
| 51 | + COALESCE(wp.placement, sp.placement) AS placement |
| 52 | + FROM submission_participants AS sp |
| 53 | + FULL OUTER JOIN winner_participants AS wp |
| 54 | + ON wp.member_id = sp.member_id |
| 55 | + AND wp.challenge_id = sp.challenge_id |
| 56 | +) |
| 57 | +SELECT |
| 58 | + cp.member_id AS "memberId", |
| 59 | + cp.member_handle AS "memberHandle", |
| 60 | + COUNT(*)::int AS "uniqueChallengesSubmitted", |
| 61 | + COUNT(*) FILTER (WHERE cp.placement = 1)::int AS "placementsOfOne", |
| 62 | + COUNT(*) FILTER (WHERE cp.placement BETWEEN 1 AND 5)::int AS "placementsOneThroughFive" |
| 63 | +FROM combined_participants AS cp |
| 64 | +GROUP BY |
| 65 | + cp.member_id, |
| 66 | + cp.member_handle |
| 67 | +ORDER BY |
| 68 | + "uniqueChallengesSubmitted" DESC, |
| 69 | + "memberHandle" ASC; |
0 commit comments