Skip to content

Commit da25aec

Browse files
authored
Merge pull request #26 from topcoder-platform/develop
New topcoder reports and CSV support
2 parents 27916f3 + dde1904 commit da25aec

13 files changed

+937
-50
lines changed
Lines changed: 76 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,76 @@
1+
WITH latest_payment AS (
2+
SELECT
3+
p.winnings_id,
4+
MAX(p.version) AS max_version
5+
FROM finance.payment p
6+
GROUP BY p.winnings_id
7+
),
8+
recent_payments AS (
9+
SELECT
10+
w.winning_id,
11+
w.winner_id,
12+
w.category,
13+
w.external_id AS challenge_id,
14+
w.created_at AS winning_created_at,
15+
p.payment_id,
16+
p.payment_status,
17+
p.installment_number,
18+
p.billing_account,
19+
p.total_amount,
20+
p.gross_amount,
21+
p.challenge_fee,
22+
p.challenge_markup,
23+
p.date_paid,
24+
p.created_at AS payment_created_at
25+
FROM finance.winnings w
26+
JOIN finance.payment p
27+
ON p.winnings_id = w.winning_id
28+
JOIN latest_payment lp
29+
ON lp.winnings_id = p.winnings_id
30+
AND lp.max_version = p.version
31+
WHERE w.type = 'PAYMENT'
32+
AND p.installment_number = 1
33+
AND p.payment_status = 'PAID'
34+
AND COALESCE(p.date_paid, p.created_at) >= (CURRENT_DATE - INTERVAL '3 months')
35+
)
36+
SELECT
37+
cl."name" AS customer,
38+
cl."codeName" AS client_codename,
39+
COALESCE(c."projectId"::text, ba."projectId") AS project_id,
40+
proj.name AS project_name,
41+
ba.id::text AS billing_account_id,
42+
ba."name" AS billing_account_name,
43+
rp.challenge_id,
44+
c."name" AS challenge_name,
45+
c."createdAt" AS challenge_created_at,
46+
rp.winner_id AS member_id,
47+
mem.handle AS member_handle,
48+
CASE
49+
WHEN rp.category::text ILIKE '%REVIEW%' THEN 'review'
50+
WHEN rp.category::text ILIKE '%COPILOT%' THEN 'copilot'
51+
ELSE 'prize'
52+
END AS payment_type,
53+
COALESCE(rp.gross_amount, rp.total_amount) AS member_payment,
54+
COALESCE(
55+
rp.challenge_fee,
56+
COALESCE(rp.gross_amount, rp.total_amount) * (rp.challenge_markup / 100.0)
57+
) AS fee,
58+
rp.payment_created_at AS payment_created_at,
59+
rp.date_paid AS paid_date
60+
FROM recent_payments rp
61+
LEFT JOIN challenges."Challenge" c
62+
ON c."id" = rp.challenge_id
63+
LEFT JOIN challenges."ChallengeBilling" cb
64+
ON cb."challengeId" = c."id"
65+
LEFT JOIN "billing-accounts"."BillingAccount" ba
66+
ON ba."id" = COALESCE(
67+
NULLIF(rp.billing_account, '')::int,
68+
NULLIF(cb."billingAccountId", '')::int
69+
)
70+
LEFT JOIN "billing-accounts"."Client" cl
71+
ON cl."id" = ba."clientId"
72+
LEFT JOIN projects.projects proj
73+
ON proj.id = c."projectId"::bigint
74+
LEFT JOIN members.member mem
75+
ON mem."userId"::text = rp.winner_id
76+
ORDER BY payment_created_at DESC;
Lines changed: 69 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,69 @@
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;

sql/reports/topcoder/mm-stats.sql

Lines changed: 60 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,60 @@
1+
WITH member_base AS (
2+
SELECT
3+
mem."userId",
4+
mem.handle,
5+
mem."firstName",
6+
mem."lastName",
7+
COALESCE(
8+
comp_code.name,
9+
comp_id.name,
10+
NULLIF(TRIM(mem."competitionCountryCode"), '')
11+
) AS competition_country,
12+
usr.create_date AS member_since
13+
FROM members."member" AS mem
14+
LEFT JOIN identity."user" AS usr
15+
ON usr.user_id::bigint = mem."userId"
16+
LEFT JOIN lookups."Country" AS comp_code
17+
ON UPPER(comp_code."countryCode") = UPPER(mem."competitionCountryCode")
18+
LEFT JOIN lookups."Country" AS comp_id
19+
ON UPPER(comp_id.id) = UPPER(mem."competitionCountryCode")
20+
WHERE mem."handleLower" = LOWER($1)
21+
)
22+
SELECT
23+
mb.handle,
24+
mb."firstName" AS first_name,
25+
mb."lastName" AS last_name,
26+
mb.competition_country,
27+
mb.member_since,
28+
marathon_stats.rating AS marathon_match_rating,
29+
marathon_stats.rank AS marathon_match_rank,
30+
max_rating.max_rating AS highest_track_rating,
31+
marathon_stats.challenges AS marathon_matches_registered,
32+
marathon_stats.wins AS marathon_match_wins,
33+
marathon_stats."topFiveFinishes" AS marathon_match_top_five_finishes,
34+
marathon_stats."avgRank" AS average_marathon_match_placement,
35+
CASE
36+
WHEN marathon_stats.challenges IS NULL
37+
OR marathon_stats.challenges = 0 THEN NULL
38+
ELSE marathon_stats.competitions::double precision
39+
/ marathon_stats.challenges::double precision
40+
END AS marathon_submission_rate
41+
FROM member_base AS mb
42+
LEFT JOIN LATERAL (
43+
SELECT MAX(mmr.rating) AS max_rating
44+
FROM members."memberMaxRating" AS mmr
45+
WHERE mmr."userId" = mb."userId"
46+
) AS max_rating ON TRUE
47+
LEFT JOIN LATERAL (
48+
SELECT mmar.*
49+
FROM members."memberStats" AS ms
50+
JOIN members."memberDataScienceStats" AS mds
51+
ON mds."memberStatsId" = ms.id
52+
JOIN members."memberMarathonStats" AS mmar
53+
ON mmar."dataScienceStatsId" = mds.id
54+
WHERE ms."userId" = mb."userId"
55+
ORDER BY
56+
CASE WHEN ms."isPrivate" THEN 1 ELSE 0 END,
57+
ms."updatedAt" DESC NULLS LAST,
58+
ms.id DESC
59+
LIMIT 1
60+
) AS marathon_stats ON TRUE;

src/app.module.ts

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -9,6 +9,7 @@ import { TopcoderReportsModule } from "./reports/topcoder/topcoder-reports.modul
99
import { StatisticsModule } from "./statistics/statistics.module";
1010
import { SfdcReportsModule } from "./reports/sfdc/sfdc-reports.module";
1111
import { ChallengesReportsModule } from "./reports/challenges/challenges-reports.module";
12+
import { ReportsModule } from "./reports/reports.module";
1213

1314
@Module({
1415
imports: [
@@ -19,6 +20,7 @@ import { ChallengesReportsModule } from "./reports/challenges/challenges-reports
1920
StatisticsModule,
2021
SfdcReportsModule,
2122
ChallengesReportsModule,
23+
ReportsModule,
2224
HealthModule,
2325
],
2426
})

src/auth/guards/permissions.guard.ts

Lines changed: 40 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -7,9 +7,14 @@ import {
77
} from "@nestjs/common";
88
import { Reflector } from "@nestjs/core";
99
import { SCOPES_KEY } from "../decorators/scopes.decorator";
10+
import { UserRoles } from "../../app-constants";
1011

1112
@Injectable()
1213
export class PermissionsGuard implements CanActivate {
14+
private static readonly adminRoles = new Set(
15+
Object.values(UserRoles).map((role) => role.toLowerCase()),
16+
);
17+
1318
constructor(private reflector: Reflector) {}
1419

1520
canActivate(context: ExecutionContext): boolean {
@@ -28,15 +33,45 @@ export class PermissionsGuard implements CanActivate {
2833
throw new UnauthorizedException("You are not authenticated.");
2934
}
3035

31-
if (requiredScopes && authUser.scopes?.length) {
32-
const hasScope = requiredScopes.some((scope) =>
33-
authUser.scopes.includes(scope),
34-
);
35-
if (hasScope) return true;
36+
if (authUser.isMachine) {
37+
const scopes: string[] = authUser.scopes ?? [];
38+
if (this.hasRequiredScope(scopes, requiredScopes)) {
39+
return true;
40+
}
41+
} else {
42+
const roles: string[] = authUser.roles ?? [];
43+
if (this.isAdmin(roles)) {
44+
return true;
45+
}
46+
47+
const scopes: string[] = authUser.scopes ?? [];
48+
if (this.hasRequiredScope(scopes, requiredScopes)) {
49+
return true;
50+
}
3651
}
3752

3853
throw new ForbiddenException(
3954
"You do not have the required permissions to access this resource.",
4055
);
4156
}
57+
58+
private hasRequiredScope(
59+
scopes: string[],
60+
requiredScopes: string[],
61+
): boolean {
62+
if (!scopes?.length) {
63+
return false;
64+
}
65+
66+
const normalizedScopes = scopes.map((scope) => scope?.toLowerCase());
67+
return requiredScopes.some((scope) =>
68+
normalizedScopes.includes(scope?.toLowerCase()),
69+
);
70+
}
71+
72+
private isAdmin(roles: string[]): boolean {
73+
return roles.some((role) =>
74+
PermissionsGuard.adminRoles.has(role?.toLowerCase()),
75+
);
76+
}
4277
}

0 commit comments

Comments
 (0)