diff --git a/sql/reports/topgear/challenge-stats-by-user.sql b/sql/reports/topgear/challenge-stats-by-user.sql new file mode 100644 index 0000000..6b7cc10 --- /dev/null +++ b/sql/reports/topgear/challenge-stats-by-user.sql @@ -0,0 +1,119 @@ +WITH base AS ( + SELECT + c.id AS challenge_id, + c.status AS challenge_status, + c."projectId" AS project_id, + c."createdAt" AS challenge_created_at, + c."endDate" AS planned_end_at + FROM challenges."Challenge" c + WHERE c.status IN ('ACTIVE','COMPLETED') +), +last_phase AS ( + SELECT + cp."challengeId" AS challenge_id, + MAX(COALESCE(cp."actualEndDate", cp."scheduledEndDate")) AS last_phase_end + FROM challenges."ChallengePhase" cp + GROUP BY cp."challengeId" +), +submissions AS ( + SELECT + s."challengeId" AS challenge_id, + s."memberId"::bigint AS member_id, + MAX(s."finalScore") AS best_final_score + FROM reviews.submission s + GROUP BY s."challengeId", s."memberId" +), +winners AS ( + SELECT + cw."challengeId" AS challenge_id, + m.handle AS winner_handle + FROM challenges."ChallengeWinner" cw + JOIN members.member m ON m."userId" = cw."userId"::bigint + WHERE cw.placement = 1 +), +billing AS ( + SELECT + cb."challengeId" AS challenge_id, + cb."billingAccountId"::bigint AS billing_account_id + FROM challenges."ChallengeBilling" cb +), +proj AS ( + SELECT + p.id AS project_id, + (p.details::jsonb -> 'project_data' ->> 'group_customer_name') AS group_customer_name, + p."billingAccountId"::bigint AS project_billing_account_id + FROM projects.projects p +), +registrants AS ( + SELECT + r."challengeId" AS challenge_id, + r."memberId"::bigint AS member_id, + COALESCE(r."memberHandle", m.handle) AS registrant_handle, + m.email AS registrant_email + FROM resources."Resource" r + JOIN resources."ResourceRole" rr + ON rr.id = r."roleId" AND rr.name = 'Submitter' + LEFT JOIN members.member m + ON m."userId" = r."memberId"::bigint +), +challenge_technology AS ( + SELECT + cs."challengeId" AS challenge_id, + s.name AS technology_name + FROM challenges."ChallengeSkill" cs + JOIN skills.skill s + ON s.id = cs."skillId"::uuid +), +base_data AS ( + SELECT + reg.registrant_handle, + reg.member_id, + reg.registrant_email, + bse.challenge_id, + bse.challenge_status, + prj.group_customer_name, + tech.technology_name, + COALESCE( + CASE WHEN bse.challenge_status = 'COMPLETED' THEN lp.last_phase_end END, + bse.planned_end_at, + bse.challenge_created_at + ) AS posting_date, + CASE WHEN sub.best_final_score IS NOT NULL THEN 1 ELSE 0 END AS did_submit, + CASE WHEN win.winner_handle = reg.registrant_handle THEN 1 ELSE 0 END AS did_win + FROM base bse + JOIN registrants reg + ON reg.challenge_id = bse.challenge_id + LEFT JOIN submissions sub + ON sub.challenge_id = bse.challenge_id + AND sub.member_id = reg.member_id + LEFT JOIN winners win + ON win.challenge_id = bse.challenge_id + LEFT JOIN last_phase lp + ON lp.challenge_id = bse.challenge_id + LEFT JOIN proj prj + ON prj.project_id = bse.project_id + LEFT JOIN billing bil + ON bil.challenge_id = bse.challenge_id + LEFT JOIN challenge_technology tech + ON tech.challenge_id = bse.challenge_id + WHERE COALESCE(bil.billing_account_id, prj.project_billing_account_id) = 80000062 +) +SELECT + bd.technology_name AS "challengeTechnology", + bd.registrant_handle AS "challengeRegistrantHandle", + bd.registrant_email AS "userEmail", + COUNT(DISTINCT bd.challenge_id) AS "challengeDistinctCount", + SUM(bd.did_submit) AS "submissionByAUser", + SUM(bd.did_win) AS "challengeStatsWins" +FROM base_data bd +WHERE + bd.posting_date BETWEEN $1::timestamptz AND $2::timestamptz + AND bd.challenge_status::text = 'COMPLETED' + AND bd.registrant_handle IS NOT NULL +GROUP BY + bd.technology_name, + bd.registrant_handle, + bd.registrant_email +ORDER BY + "challengeDistinctCount" DESC +LIMIT 1000; diff --git a/src/app-constants.ts b/src/app-constants.ts index 9a7cd99..62ca7fa 100644 --- a/src/app-constants.ts +++ b/src/app-constants.ts @@ -5,6 +5,7 @@ export const Scopes = { TopgearCancelledChallenge: "reports:topgear-cancelled-challenge", AllReports: "reports:all", TopgearChallengeTechnology: "reports:topgear-challenge-technology", + TopgearChallengeStatsByUser: "reports:topgear-challenge-stats-by-user", TopgearChallengeRegistrantDetails: "reports:topgear-challenge-registrant-details", SFDC: { diff --git a/src/reports/topgear/dtos/challenge-stats-by-user.dto.ts b/src/reports/topgear/dtos/challenge-stats-by-user.dto.ts new file mode 100644 index 0000000..6e94ba2 --- /dev/null +++ b/src/reports/topgear/dtos/challenge-stats-by-user.dto.ts @@ -0,0 +1,23 @@ +import { ApiProperty } from "@nestjs/swagger"; + +export class ChallengeStatsByUserDto { + @ApiProperty({ description: "Challenge technology" }) + challengeTechnology: string; + + @ApiProperty({ description: "Handle of the registrant/user" }) + challengeRegistrantHandle: string; + + @ApiProperty({ description: "Email of the user" }) + userEmail: string; + + @ApiProperty({ + description: "Count of distinct challenges the user participated in", + }) + challengeDistinctCount: number; + + @ApiProperty({ description: "Number of submissions made by the user" }) + submissionByAUser: number; + + @ApiProperty({ description: "Number of challenges won by the user" }) + challengeStatsWins: number; +} diff --git a/src/reports/topgear/topgear-reports.controller.ts b/src/reports/topgear/topgear-reports.controller.ts index 459143f..f2eec2a 100644 --- a/src/reports/topgear/topgear-reports.controller.ts +++ b/src/reports/topgear/topgear-reports.controller.ts @@ -13,6 +13,7 @@ import { Scopes as AppScopes } from "../../app-constants"; import { TopgearReportsService } from "./topgear-reports.service"; import { ChallengesCountBySkillDto } from "./dtos/submissions-review.dto"; +import { ChallengeStatsByUserDto } from "./dtos/challenge-stats-by-user.dto"; @ApiTags("Topgear Reports") @Controller("/topgear") @@ -28,6 +29,18 @@ export class TopgearReportsController { return this.reports.getTopgearHourly(); } + @Get("challenge-stats-by-user") + @UseGuards(PermissionsGuard) + @Scopes(AppScopes.AllReports, AppScopes.TopgearChallengeStatsByUser) + @ApiBearerAuth() + @ApiOperation({ summary: "Get challenge stats per user" }) + async getChallengeStatsByUser( + @Query("start_date") startDate?: string, + @Query("end_date") endDate?: string, + ): Promise { + return this.reports.getChallengeStatsByUser({ startDate, endDate }); + } + @Get("challenges-count-by-skill") @UseGuards(PermissionsGuard) @Scopes(AppScopes.AllReports, AppScopes.TopgearChallengeTechnology) diff --git a/src/reports/topgear/topgear-reports.service.ts b/src/reports/topgear/topgear-reports.service.ts index 44ee9cc..dc845a0 100644 --- a/src/reports/topgear/topgear-reports.service.ts +++ b/src/reports/topgear/topgear-reports.service.ts @@ -6,6 +6,7 @@ import { defaultStartDate, defaultEndDate, } from "../../common/validation.util"; +import { ChallengeStatsByUserDto } from "./dtos/challenge-stats-by-user.dto"; @Injectable() export class TopgearReportsService { @@ -19,6 +20,23 @@ export class TopgearReportsService { return this.db.query(query); } + async getChallengeStatsByUser(opts: { + startDate?: string; + endDate?: string; + }): Promise { + const startDate = opts.startDate ? new Date(opts.startDate) : new Date(0); + const endDate = opts.endDate ? new Date(opts.endDate) : new Date(); + + if (startDate > endDate) { + throw new BadRequestException("start_date must be <= end_date"); + } + + const query = this.sql.load("reports/topgear/challenge-stats-by-user.sql"); + return this.db.query(query, [ + startDate, + endDate + ]); + } async getTopgearRegistrantsDetails(opts: { start?: string; end?: string }) { const startDate = parseOptionalDate(opts.start) ?? defaultStartDate(); const endDate = parseOptionalDate(opts.end) ?? defaultEndDate();