|
| 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