Skip to content

Commit a221c9b

Browse files
committed
Major cleanup to perfectly match Looker fields so we have to do less in community app.
1 parent 160eebf commit a221c9b

19 files changed

+308
-163
lines changed

package.json

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,7 @@
2323
"class-transformer": "^0.5.1",
2424
"class-validator": "^0.14.0",
2525
"date-fns": "^3.6.0",
26+
"i18n-iso-countries": "^3.7.1",
2627
"json-stringify-safe": "^5.0.1",
2728
"pg": "^8.11.5",
2829
"reflect-metadata": "^0.1.13",

sql/reports/statistics/design/design-countries-represented.sql

Lines changed: 11 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -21,9 +21,14 @@ member_country AS (
2121
)
2222
SELECT
2323
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;
29-
24+
members_count AS "user.count",
25+
DENSE_RANK() OVER (ORDER BY members_count DESC, country_code ASC)::int AS rank
26+
FROM (
27+
SELECT
28+
country_code,
29+
COUNT(*)::bigint AS members_count
30+
FROM member_country
31+
WHERE country_code IS NOT NULL
32+
GROUP BY country_code
33+
) aggregated
34+
ORDER BY "user.count" DESC, country_code ASC;
Lines changed: 28 additions & 18 deletions
Original file line numberDiff line numberDiff line change
@@ -1,19 +1,29 @@
1+
WITH f2f_wins AS (
2+
SELECT
3+
s."memberId"::bigint AS user_id,
4+
COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) AS handle,
5+
COUNT(DISTINCT s."challengeId")::int AS wins_count
6+
FROM reviews.submission s
7+
JOIN challenges."Challenge" c
8+
ON c.id = s."challengeId"
9+
JOIN challenges."ChallengeType" ct
10+
ON ct.id = c."typeId"
11+
JOIN challenges."ChallengeTrack" tr
12+
ON tr.id = c."trackId"
13+
LEFT JOIN members.member m
14+
ON m."userId"::text = s."memberId"::text
15+
WHERE s.placement = 1
16+
AND tr.abbreviation = 'DS'
17+
AND ct.abbreviation = 'F2F'
18+
AND COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) IS NOT NULL
19+
GROUP BY s."memberId", m.handle
20+
)
121
SELECT
2-
m."userId" AS member_id,
3-
m.handle AS handle,
4-
COUNT(DISTINCT s."challengeId")::int AS wins_count,
5-
COUNT(DISTINCT s."challengeId")::int AS count
6-
FROM reviews.submission s
7-
JOIN challenges."Challenge" c
8-
ON c.id = s."challengeId"
9-
JOIN challenges."ChallengeType" ct
10-
ON ct.id = c."typeId"
11-
JOIN challenges."ChallengeTrack" tr
12-
ON tr.id = c."trackId"
13-
JOIN members.member m
14-
ON m."userId"::text = s."memberId"::text
15-
WHERE s.placement = 1
16-
AND tr.abbreviation = 'DS'
17-
AND ct.abbreviation = 'F2F'
18-
GROUP BY m."userId", m.handle
19-
ORDER BY wins_count DESC, handle ASC;
22+
fw.handle AS "challenge_stats.winner_handle",
23+
mmr.rating AS "member_profile_advanced.max_rating",
24+
fw.wins_count AS "challenge_stats.count",
25+
DENSE_RANK() OVER (ORDER BY fw.wins_count DESC, fw.handle ASC)::int AS rank
26+
FROM f2f_wins fw
27+
LEFT JOIN members."memberMaxRating" mmr
28+
ON mmr."userId" = fw.user_id
29+
ORDER BY "challenge_stats.count" DESC, "challenge_stats.winner_handle" ASC;
Lines changed: 26 additions & 21 deletions
Original file line numberDiff line numberDiff line change
@@ -1,28 +1,33 @@
1-
WITH winners AS (
2-
SELECT s."memberId"::text AS member_id
3-
FROM reviews.submission s
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
46
JOIN challenges."Challenge" c
5-
ON c.id = s."challengeId"
7+
ON c.id = cw."challengeId"
68
JOIN challenges."ChallengeTrack" tr
79
ON tr.id = c."trackId"
8-
WHERE s.placement = 1
9-
AND tr.abbreviation = 'DS'
10+
LEFT JOIN members.member m
11+
ON m."userId" = cw."userId"::bigint
12+
WHERE tr.abbreviation = 'DS'
13+
AND c.status = 'COMPLETED'
14+
AND cw.placement = 1
1015
),
11-
winners_country AS (
16+
placements AS (
1217
SELECT
13-
COALESCE(
14-
NULLIF(TRIM(m."homeCountryCode"), ''),
15-
NULLIF(TRIM(m."competitionCountryCode"), '')
16-
) AS country_code
17-
FROM winners w
18-
JOIN members.member m
19-
ON m."userId"::text = w.member_id
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
2024
)
2125
SELECT
22-
country_code,
23-
COUNT(*)::bigint AS first_place_count
24-
FROM winners_country
25-
WHERE country_code IS NOT NULL
26-
GROUP BY country_code
27-
ORDER BY first_place_count DESC, country_code ASC;
28-
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;

sql/reports/statistics/design/first-time-design-submitters.sql

Lines changed: 2 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -11,12 +11,10 @@ WITH design_first_submissions AS (
1111
GROUP BY s."memberId"
1212
)
1313
SELECT
14-
m."userId" AS member_id,
15-
m.handle AS handle,
16-
d.first_submission_date
14+
m.handle AS handle,
15+
d.first_submission_date::date AS first_submission_date
1716
FROM design_first_submissions d
1817
JOIN members.member m
1918
ON m."userId"::text = d.member_id
2019
WHERE d.first_submission_date >= NOW() - INTERVAL '3 months'
2120
ORDER BY d.first_submission_date DESC, handle ASC;
22-

sql/reports/statistics/design/lux-first-place-wins.sql

Lines changed: 5 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -28,12 +28,13 @@ placements AS (
2828
GROUP BY user_id, handle
2929
)
3030
SELECT
31-
p.handle,
32-
p.placements_count AS wins_count,
31+
p.handle AS "challenge_stats.winner_handle",
32+
p.handle AS handle,
33+
p.placements_count AS "challenge_stats.count",
3334
p.placements_count AS count,
34-
mmr.rating AS max_rating,
35+
mmr.rating AS "member_profile_advanced.max_rating",
3536
DENSE_RANK() OVER (ORDER BY p.placements_count DESC, p.handle ASC)::int AS rank
3637
FROM placements p
3738
LEFT JOIN members."memberMaxRating" mmr
3839
ON mmr."userId" = p.user_id
39-
ORDER BY wins_count DESC, handle ASC;
40+
ORDER BY "challenge_stats.count" DESC, "challenge_stats.winner_handle" ASC;
Lines changed: 16 additions & 15 deletions
Original file line numberDiff line numberDiff line change
@@ -1,30 +1,31 @@
1-
WITH member_placements AS (
1+
WITH placements AS (
22
SELECT
3-
m."userId" AS member_id,
4-
m.handle AS handle,
3+
s."memberId"::bigint AS user_id,
4+
COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) AS handle,
55
COUNT(DISTINCT s."challengeId")::int AS placements_count
66
FROM reviews.submission s
77
JOIN challenges."Challenge" c
88
ON c.id = s."challengeId"
99
JOIN challenges."ChallengeTrack" tr
1010
ON tr.id = c."trackId"
11-
JOIN members.member m
11+
LEFT JOIN members.member m
1212
ON m."userId"::text = s."memberId"::text
1313
WHERE s.placement IS NOT NULL
1414
AND s.placement > 0
1515
AND tr.abbreviation = 'DS'
1616
AND (
17-
c.name ILIKE 'RUX%'
18-
OR c.name ILIKE 'TCO RUX%'
17+
c.name ILIKE 'LUX%'
18+
OR c.name ILIKE 'TCO LUX%'
1919
)
20-
GROUP BY m."userId", m.handle
20+
AND COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) IS NOT NULL
21+
GROUP BY s."memberId", m.handle
2122
)
2223
SELECT
23-
member_id,
24-
handle,
25-
NULL::int AS max_rating,
26-
placements_count,
27-
placements_count AS count,
28-
RANK() OVER (ORDER BY placements_count DESC, handle ASC) AS rank
29-
FROM member_placements
30-
ORDER BY placements_count DESC, handle ASC;
24+
p.handle AS "submitter.handle",
25+
mmr.rating AS "submitter_profile.max_rating",
26+
p.placements_count AS "challenge.count",
27+
DENSE_RANK() OVER (ORDER BY p.placements_count DESC, p.handle ASC)::int AS rank
28+
FROM placements p
29+
LEFT JOIN members."memberMaxRating" mmr
30+
ON mmr."userId" = p.user_id
31+
ORDER BY "challenge.count" DESC, "submitter.handle" ASC;
Lines changed: 16 additions & 13 deletions
Original file line numberDiff line numberDiff line change
@@ -1,29 +1,32 @@
1-
WITH member_wins AS (
1+
WITH rux_wins AS (
22
SELECT
3-
m."userId" AS member_id,
4-
m.handle AS handle,
3+
s."memberId"::bigint AS user_id,
4+
COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) AS handle,
55
COUNT(DISTINCT s."challengeId")::int AS wins_count
66
FROM reviews.submission s
77
JOIN challenges."Challenge" c
88
ON c.id = s."challengeId"
99
JOIN challenges."ChallengeTrack" tr
1010
ON tr.id = c."trackId"
11-
JOIN members.member m
11+
LEFT JOIN members.member m
1212
ON m."userId"::text = s."memberId"::text
1313
WHERE s.placement = 1
1414
AND tr.abbreviation = 'DS'
1515
AND (
1616
c.name ILIKE 'RUX%'
1717
OR c.name ILIKE 'TCO RUX%'
1818
)
19-
GROUP BY m."userId", m.handle
19+
AND COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) IS NOT NULL
20+
GROUP BY s."memberId", m.handle
2021
)
2122
SELECT
22-
member_id,
23-
handle,
24-
NULL::int AS max_rating,
25-
wins_count,
26-
wins_count AS count,
27-
RANK() OVER (ORDER BY wins_count DESC, handle ASC) AS rank
28-
FROM member_wins
29-
ORDER BY wins_count DESC, handle ASC;
23+
rw.handle AS "challenge_stats.winner_handle",
24+
rw.handle AS handle,
25+
rw.wins_count AS "challenge_stats.count",
26+
rw.wins_count AS count,
27+
mmr.rating AS "member_profile_advanced.max_rating",
28+
DENSE_RANK() OVER (ORDER BY rw.wins_count DESC, rw.handle ASC)::int AS rank
29+
FROM rux_wins rw
30+
LEFT JOIN members."memberMaxRating" mmr
31+
ON mmr."userId" = rw.user_id
32+
ORDER BY "challenge_stats.count" DESC, "challenge_stats.winner_handle" ASC;
Lines changed: 14 additions & 13 deletions
Original file line numberDiff line numberDiff line change
@@ -1,14 +1,14 @@
1-
WITH member_placements AS (
1+
WITH placements AS (
22
SELECT
3-
m."userId" AS member_id,
4-
m.handle AS handle,
3+
s."memberId"::bigint AS user_id,
4+
COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) AS handle,
55
COUNT(DISTINCT s."challengeId")::int AS placements_count
66
FROM reviews.submission s
77
JOIN challenges."Challenge" c
88
ON c.id = s."challengeId"
99
JOIN challenges."ChallengeTrack" tr
1010
ON tr.id = c."trackId"
11-
JOIN members.member m
11+
LEFT JOIN members.member m
1212
ON m."userId"::text = s."memberId"::text
1313
WHERE s.placement IS NOT NULL
1414
AND s.placement > 0
@@ -17,14 +17,15 @@ WITH member_placements AS (
1717
c.name ILIKE 'RUX%'
1818
OR c.name ILIKE 'TCO RUX%'
1919
)
20-
GROUP BY m."userId", m.handle
20+
AND COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) IS NOT NULL
21+
GROUP BY s."memberId", m.handle
2122
)
2223
SELECT
23-
member_id,
24-
handle,
25-
NULL::int AS max_rating,
26-
placements_count,
27-
placements_count AS count,
28-
RANK() OVER (ORDER BY placements_count DESC, handle ASC) AS rank
29-
FROM member_placements
30-
ORDER BY placements_count DESC, handle ASC;
24+
p.handle AS "submitter.handle",
25+
mmr.rating AS "submitter_profile.max_rating",
26+
p.placements_count AS "challenge.count",
27+
DENSE_RANK() OVER (ORDER BY p.placements_count DESC, p.handle ASC)::int AS rank
28+
FROM placements p
29+
LEFT JOIN members."memberMaxRating" mmr
30+
ON mmr."userId" = p.user_id
31+
ORDER BY "challenge.count" DESC, "submitter.handle" ASC;
Lines changed: 28 additions & 18 deletions
Original file line numberDiff line numberDiff line change
@@ -1,19 +1,29 @@
1+
WITH design_wins AS (
2+
SELECT
3+
s."memberId"::bigint AS user_id,
4+
COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) AS handle,
5+
COUNT(DISTINCT s."challengeId")::int AS wins_count
6+
FROM reviews.submission s
7+
JOIN challenges."Challenge" c
8+
ON c.id = s."challengeId"
9+
JOIN challenges."ChallengeType" ct
10+
ON ct.id = c."typeId"
11+
JOIN challenges."ChallengeTrack" tr
12+
ON tr.id = c."trackId"
13+
LEFT JOIN members.member m
14+
ON m."userId"::text = s."memberId"::text
15+
WHERE s.placement = 1
16+
AND tr.abbreviation = 'DS'
17+
AND ct.abbreviation = 'CH'
18+
AND COALESCE(NULLIF(TRIM(m.handle), ''), m.handle) IS NOT NULL
19+
GROUP BY s."memberId", m.handle
20+
)
121
SELECT
2-
m."userId" AS member_id,
3-
m.handle AS handle,
4-
COUNT(DISTINCT s."challengeId")::int AS wins_count,
5-
COUNT(DISTINCT s."challengeId")::int AS count
6-
FROM reviews.submission s
7-
JOIN challenges."Challenge" c
8-
ON c.id = s."challengeId"
9-
JOIN challenges."ChallengeType" ct
10-
ON ct.id = c."typeId"
11-
JOIN challenges."ChallengeTrack" tr
12-
ON tr.id = c."trackId"
13-
JOIN members.member m
14-
ON m."userId"::text = s."memberId"::text
15-
WHERE s.placement = 1
16-
AND tr.abbreviation = 'DS'
17-
AND ct.abbreviation = 'CH'
18-
GROUP BY m."userId", m.handle
19-
ORDER BY wins_count DESC, handle ASC;
22+
dw.handle AS "challenge_stats.winner_handle",
23+
mmr.rating AS "member_profile_advanced.max_rating",
24+
dw.wins_count AS "challenge_stats.count",
25+
DENSE_RANK() OVER (ORDER BY dw.wins_count DESC, dw.handle ASC)::int AS rank
26+
FROM design_wins dw
27+
LEFT JOIN members."memberMaxRating" mmr
28+
ON mmr."userId" = dw.user_id
29+
ORDER BY "challenge_stats.count" DESC, "challenge_stats.winner_handle" ASC;

0 commit comments

Comments
 (0)