Skip to content

Commit 83852d0

Browse files
committed
Additional statistics endpoints for the remaining development and qa options
1 parent adda2d0 commit 83852d0

19 files changed

+450
-24
lines changed
Lines changed: 37 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,37 @@
1+
WITH skill_counts AS (
2+
SELECT
3+
s.name AS skill_name,
4+
COUNT(DISTINCT c.id)::bigint AS challenge_count
5+
FROM skills.work_skill ws
6+
JOIN skills.source_type st
7+
ON st.id = ws.work_type_id
8+
JOIN skills.skill s
9+
ON s.id = ws.skill_id
10+
JOIN challenges."Challenge" c
11+
ON c.id = ws.work_id
12+
JOIN challenges."ChallengeTrack" tr
13+
ON tr.id = c."trackId"
14+
LEFT JOIN challenges."ChallengeType" ct
15+
ON ct.id = c."typeId"
16+
WHERE st.name = 'challenge'
17+
AND tr.abbreviation = 'DE'
18+
AND s.name IS NOT NULL
19+
AND s.deleted_at IS NULL
20+
AND COALESCE(ct."isTask", false) = false
21+
AND NOT EXISTS (
22+
SELECT 1
23+
FROM UNNEST(c.groups) AS gid(group_id)
24+
JOIN groups."Group" g
25+
ON g.id = gid.group_id
26+
WHERE g.name ILIKE '%wipro%'
27+
OR g.name ILIKE '%veterans%'
28+
)
29+
GROUP BY s.name
30+
)
31+
SELECT
32+
skill_name AS "challenge_technology.name",
33+
challenge_count AS "challenge_stats.count",
34+
DENSE_RANK() OVER (ORDER BY challenge_count DESC, skill_name ASC)::int AS rank
35+
FROM skill_counts
36+
ORDER BY "challenge_stats.count" DESC, "challenge_technology.name" ASC
37+
LIMIT 500;
Lines changed: 33 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,33 @@
1+
WITH raw_winners AS (
2+
SELECT
3+
cw."userId"::bigint AS user_id,
4+
COALESCE(NULLIF(TRIM(cw.handle), ''), m.handle) AS handle
5+
FROM challenges."ChallengeWinner" cw
6+
JOIN challenges."Challenge" c
7+
ON c.id = cw."challengeId"
8+
JOIN challenges."ChallengeTrack" tr
9+
ON tr.id = c."trackId"
10+
LEFT JOIN members.member m
11+
ON m."userId" = cw."userId"::bigint
12+
WHERE tr.abbreviation = 'Dev'
13+
AND c.status = 'COMPLETED'
14+
AND cw.placement = 1
15+
),
16+
placements AS (
17+
SELECT
18+
user_id,
19+
handle,
20+
COUNT(*)::int AS wins
21+
FROM raw_winners
22+
WHERE handle IS NOT NULL
23+
GROUP BY user_id, handle
24+
)
25+
SELECT
26+
p.handle AS "challenge_stats.winner_handle",
27+
mmr.rating AS "member_profile_advanced.max_rating",
28+
p.wins AS "challenge_stats.count",
29+
DENSE_RANK() OVER (ORDER BY p.wins DESC, p.handle ASC)::int AS rank
30+
FROM placements p
31+
LEFT JOIN members."memberMaxRating" mmr
32+
ON mmr."userId" = p.user_id
33+
ORDER BY "challenge_stats.count" DESC, "challenge_stats.winner_handle" ASC;
Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,28 @@
1+
WITH development_submitters AS (
2+
SELECT DISTINCT
3+
s."memberId"::text AS member_id
4+
FROM reviews.submission s
5+
JOIN challenges."Challenge" c
6+
ON c.id = s."challengeId"
7+
JOIN challenges."ChallengeTrack" tr
8+
ON tr.id = c."trackId"
9+
WHERE tr.abbreviation = 'Dev'
10+
),
11+
member_country AS (
12+
SELECT
13+
ds.member_id,
14+
COALESCE(
15+
NULLIF(TRIM(m."homeCountryCode"), ''),
16+
NULLIF(TRIM(m."competitionCountryCode"), '')
17+
) AS country_code
18+
FROM development_submitters ds
19+
JOIN members.member m
20+
ON m."userId"::text = ds.member_id
21+
)
22+
SELECT
23+
country_code,
24+
COUNT(*)::bigint AS members_count
25+
FROM member_country
26+
WHERE country_code IS NOT NULL
27+
GROUP BY country_code
28+
ORDER BY members_count DESC, country_code ASC;
Lines changed: 36 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,36 @@
1+
WITH raw_winners AS (
2+
SELECT
3+
cw."userId"::bigint AS user_id,
4+
COALESCE(NULLIF(TRIM(cw.handle), ''), m.handle) AS handle
5+
FROM challenges."ChallengeWinner" cw
6+
JOIN challenges."Challenge" c
7+
ON c.id = cw."challengeId"
8+
JOIN challenges."ChallengeType" ct
9+
ON ct.id = c."typeId"
10+
JOIN challenges."ChallengeTrack" tr
11+
ON tr.id = c."trackId"
12+
LEFT JOIN members.member m
13+
ON m."userId" = cw."userId"::bigint
14+
WHERE tr.abbreviation = 'Dev'
15+
AND ct.abbreviation = 'F2F'
16+
AND c.status = 'COMPLETED'
17+
AND cw.placement = 1
18+
),
19+
placements AS (
20+
SELECT
21+
user_id,
22+
handle,
23+
COUNT(*)::int AS wins
24+
FROM raw_winners
25+
WHERE handle IS NOT NULL
26+
GROUP BY user_id, handle
27+
)
28+
SELECT
29+
p.handle AS "challenge_stats.winner_handle",
30+
mmr.rating AS "member_profile_advanced.max_rating",
31+
p.wins AS "challenge_stats.count",
32+
DENSE_RANK() OVER (ORDER BY p.wins DESC, p.handle ASC)::int AS rank
33+
FROM placements p
34+
LEFT JOIN members."memberMaxRating" mmr
35+
ON mmr."userId" = p.user_id
36+
ORDER BY "challenge_stats.count" DESC, "challenge_stats.winner_handle" ASC;
Lines changed: 33 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,33 @@
1+
WITH raw_winners AS (
2+
SELECT
3+
cw."userId"::bigint AS user_id,
4+
COALESCE(NULLIF(TRIM(cw.handle), ''), m.handle) AS handle
5+
FROM challenges."ChallengeWinner" cw
6+
JOIN challenges."Challenge" c
7+
ON c.id = cw."challengeId"
8+
JOIN challenges."ChallengeTrack" tr
9+
ON tr.id = c."trackId"
10+
LEFT JOIN members.member m
11+
ON m."userId" = cw."userId"::bigint
12+
WHERE tr.abbreviation = 'Dev'
13+
AND c.status = 'COMPLETED'
14+
AND cw.placement = 1
15+
),
16+
placements AS (
17+
SELECT
18+
user_id,
19+
handle,
20+
COUNT(*)::int AS wins
21+
FROM raw_winners
22+
WHERE handle IS NOT NULL
23+
GROUP BY user_id, handle
24+
)
25+
SELECT
26+
p.handle AS "challenge_stats.registrant_handle",
27+
mmr.rating AS "member_profile_advanced.max_rating",
28+
p.wins AS "challenge_stats.count",
29+
DENSE_RANK() OVER (ORDER BY p.wins DESC, p.handle ASC)::int AS rank
30+
FROM placements p
31+
LEFT JOIN members."memberMaxRating" mmr
32+
ON mmr."userId" = p.user_id
33+
ORDER BY "challenge_stats.count" DESC, "challenge_stats.registrant_handle" ASC;
Lines changed: 45 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,45 @@
1+
WITH development_submissions_ranked AS (
2+
SELECT
3+
s."memberId"::bigint AS member_id,
4+
s."challengeId" AS challenge_id,
5+
s."submittedDate" AS submitted_date,
6+
ROW_NUMBER() OVER (
7+
PARTITION BY s."memberId"
8+
ORDER BY s."submittedDate" ASC, s."challengeId" ASC
9+
) AS submission_rank
10+
FROM reviews.submission s
11+
JOIN challenges."Challenge" c
12+
ON c.id = s."challengeId"
13+
JOIN challenges."ChallengeTrack" tr
14+
ON tr.id = c."trackId"
15+
WHERE tr.abbreviation = 'Dev'
16+
),
17+
development_first_submissions AS (
18+
SELECT
19+
member_id,
20+
challenge_id,
21+
submitted_date
22+
FROM development_submissions_ranked
23+
WHERE submission_rank = 1
24+
)
25+
SELECT
26+
m.handle AS "user.handle",
27+
c.name AS "challenge.challenge_name",
28+
dfs.submitted_date::date AS "newest_submitters.submit_date_date",
29+
max_rating.rating AS "submitter_profile.max_rating"
30+
FROM development_first_submissions dfs
31+
JOIN members.member m
32+
ON m."userId" = dfs.member_id
33+
JOIN challenges."Challenge" c
34+
ON c.id = dfs.challenge_id
35+
LEFT JOIN LATERAL (
36+
SELECT
37+
mmr.rating
38+
FROM members."memberMaxRating" mmr
39+
WHERE mmr."userId" = dfs.member_id
40+
ORDER BY mmr.rating DESC NULLS LAST
41+
LIMIT 1
42+
) max_rating
43+
ON TRUE
44+
WHERE dfs.submitted_date >= NOW() - INTERVAL '3 months'
45+
ORDER BY "newest_submitters.submit_date_date" DESC, "user.handle" ASC;
Lines changed: 34 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,34 @@
1+
WITH raw_winners AS (
2+
SELECT
3+
cw."userId"::bigint AS user_id,
4+
COALESCE(NULLIF(TRIM(cw.handle), ''), m.handle) AS handle
5+
FROM challenges."ChallengeWinner" cw
6+
JOIN challenges."Challenge" c
7+
ON c.id = cw."challengeId"
8+
JOIN challenges."ChallengeTrack" tr
9+
ON tr.id = c."trackId"
10+
LEFT JOIN members.member m
11+
ON m."userId" = cw."userId"::bigint
12+
WHERE tr.abbreviation = 'Dev'
13+
AND c.status = 'COMPLETED'
14+
AND cw.placement = 1
15+
AND c.name ILIKE '%prototype%'
16+
),
17+
placements AS (
18+
SELECT
19+
user_id,
20+
handle,
21+
COUNT(*)::int AS wins
22+
FROM raw_winners
23+
WHERE handle IS NOT NULL
24+
GROUP BY user_id, handle
25+
)
26+
SELECT
27+
p.handle AS "challenge_stats.winner_handle",
28+
mmr.rating AS "member_profile_advanced.max_rating",
29+
p.wins AS "challenge_stats.count",
30+
DENSE_RANK() OVER (ORDER BY p.wins DESC, p.handle ASC)::int AS rank
31+
FROM placements p
32+
LEFT JOIN members."memberMaxRating" mmr
33+
ON mmr."userId" = p.user_id
34+
ORDER BY "challenge_stats.count" DESC, "challenge_stats.winner_handle" ASC;

sql/reports/statistics/qa/wins.sql

Lines changed: 33 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,33 @@
1+
WITH raw_winners AS (
2+
SELECT
3+
cw."userId"::bigint AS user_id,
4+
COALESCE(NULLIF(TRIM(cw.handle), ''), m.handle) AS handle
5+
FROM challenges."ChallengeWinner" cw
6+
JOIN challenges."Challenge" c
7+
ON c.id = cw."challengeId"
8+
JOIN challenges."ChallengeTrack" tr
9+
ON tr.id = c."trackId"
10+
LEFT JOIN members.member m
11+
ON m."userId" = cw."userId"::bigint
12+
WHERE tr.abbreviation = 'QA'
13+
AND c.status = 'COMPLETED'
14+
AND cw.placement = 1
15+
),
16+
placements AS (
17+
SELECT
18+
user_id,
19+
handle,
20+
COUNT(*)::int AS wins
21+
FROM raw_winners
22+
WHERE handle IS NOT NULL
23+
GROUP BY user_id, handle
24+
)
25+
SELECT
26+
p.handle AS "challenge_stats.registrant_handle",
27+
mmr.rating AS "member_profile_advanced.max_rating",
28+
p.wins AS first_place_winner_count,
29+
DENSE_RANK() OVER (ORDER BY p.wins DESC, p.handle ASC)::int AS rank
30+
FROM placements p
31+
LEFT JOIN members."memberMaxRating" mmr
32+
ON mmr."userId" = p.user_id
33+
ORDER BY first_place_winner_count DESC, "challenge_stats.registrant_handle" ASC;

src/reports/topgear/topgear-reports.service.ts

Lines changed: 4 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -25,18 +25,17 @@ export class TopgearReportsService {
2525
startDate?: string;
2626
endDate?: string;
2727
}): Promise<ChallengeStatsByUserDto[]> {
28-
const startDate = opts.startDate ? new Date(opts.startDate) : subDays(new Date(), 7);
28+
const startDate = opts.startDate
29+
? new Date(opts.startDate)
30+
: subDays(new Date(), 7);
2931
const endDate = opts.endDate ? new Date(opts.endDate) : new Date();
3032

3133
if (startDate > endDate) {
3234
throw new BadRequestException("start_date must be <= end_date");
3335
}
3436

3537
const query = this.sql.load("reports/topgear/challenge-stats-by-user.sql");
36-
return this.db.query<ChallengeStatsByUserDto>(query, [
37-
startDate,
38-
endDate
39-
]);
38+
return this.db.query<ChallengeStatsByUserDto>(query, [startDate, endDate]);
4039
}
4140
async getTopgearRegistrantsDetails(opts: { start?: string; end?: string }) {
4241
const startDate = parseOptionalDate(opts.start) ?? defaultStartDate();

src/statistics/design-statistics.service.ts

Lines changed: 4 additions & 12 deletions
Original file line numberDiff line numberDiff line change
@@ -10,16 +10,12 @@ export class DesignStatisticsService {
1010
) {}
1111

1212
async getUiDesignWins() {
13-
const q = this.sql.load(
14-
"reports/statistics/design/ui-design-wins.sql",
15-
);
13+
const q = this.sql.load("reports/statistics/design/ui-design-wins.sql");
1614
return this.db.query(q);
1715
}
1816

1917
async getDesignF2FWins() {
20-
const q = this.sql.load(
21-
"reports/statistics/design/design-f2f-wins.sql",
22-
);
18+
const q = this.sql.load("reports/statistics/design/design-f2f-wins.sql");
2319
return this.db.query(q);
2420
}
2521

@@ -52,9 +48,7 @@ export class DesignStatisticsService {
5248
}
5349

5450
async getWireframeWins() {
55-
const q = this.sql.load(
56-
"reports/statistics/design/wireframe-wins.sql",
57-
);
51+
const q = this.sql.load("reports/statistics/design/wireframe-wins.sql");
5852
return this.db.query(q);
5953
}
6054

@@ -66,9 +60,7 @@ export class DesignStatisticsService {
6660
}
6761

6862
async getLuxPlacements() {
69-
const q = this.sql.load(
70-
"reports/statistics/design/lux-placements.sql",
71-
);
63+
const q = this.sql.load("reports/statistics/design/lux-placements.sql");
7264
return this.db.query(q);
7365
}
7466
}

0 commit comments

Comments
 (0)