From d5ad26aa5e3d1155650b2dee7fc4d341c4de4319 Mon Sep 17 00:00:00 2001 From: Hentry Martin Date: Tue, 30 Sep 2025 00:06:07 +0200 Subject: [PATCH 1/4] feat: topgear app winner badges report --- .../topgear/challenge-stats-by-user.sql | 106 +++++++++++++++ .../topgear/challenge-technology-by-user.sql | 122 ++++++++++++++++++ src/app-constants.ts | 2 + .../dtos/challenge-stats-by-user.dto.ts | 18 +++ .../dtos/challenge-technology-by-user.dto.ts | 24 ++++ .../topgear/topgear-reports.controller.ts | 24 ++++ .../topgear/topgear-reports.service.ts | 24 ++++ 7 files changed, 320 insertions(+) create mode 100644 sql/reports/topgear/challenge-stats-by-user.sql create mode 100644 sql/reports/topgear/challenge-technology-by-user.sql create mode 100644 src/reports/topgear/dtos/challenge-stats-by-user.dto.ts create mode 100644 src/reports/topgear/dtos/challenge-technology-by-user.dto.ts 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..398dd62 --- /dev/null +++ b/sql/reports/topgear/challenge-stats-by-user.sql @@ -0,0 +1,106 @@ +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 +), +base_data AS ( + SELECT + reg.registrant_handle, + reg.member_id, + reg.registrant_email, + bse.challenge_id, + bse.challenge_status, + prj.group_customer_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 + WHERE COALESCE(bil.billing_account_id, prj.project_billing_account_id) = 80000062 +) +SELECT + 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.registrant_handle, + bd.registrant_email +ORDER BY + "challenge_stats.count_distinct_challenge" DESC +LIMIT 1000; diff --git a/sql/reports/topgear/challenge-technology-by-user.sql b/sql/reports/topgear/challenge-technology-by-user.sql new file mode 100644 index 0000000..a5d693e --- /dev/null +++ b/sql/reports/topgear/challenge-technology-by-user.sql @@ -0,0 +1,122 @@ +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.registrant_email, + reg.member_id, + bse.challenge_id, + bse.challenge_status, + prj.group_customer_name, + tech.technology_name, + COALESCE(bil.billing_account_id, prj.project_billing_account_id) AS billing_account_id, + COALESCE( + CASE WHEN bse.challenge_status = 'COMPLETED' THEN lp.last_phase_end END, + bse.planned_end_at, + bse.challenge_created_at + ) AS posting_date, + (sub.best_final_score IS NOT NULL) AS has_submission, + (win.winner_handle = reg.registrant_handle) AS is_winner + 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 "challengeTechnologyName", + bd.registrant_handle AS "challengeRegistrantHandle", + bd.registrant_email AS "userEmail", + bd.billing_account_id AS "billingAccountID", + COUNT(DISTINCT bd.challenge_id) AS "challengeDistinctCount", + COUNT(DISTINCT CASE WHEN bd.has_submission THEN bd.challenge_id END) AS "submissionByAUser", + COUNT(DISTINCT CASE WHEN bd.is_winner THEN bd.challenge_id END) AS "challengeStatsWins" +FROM base_data bd +WHERE + -- past month for example (adjust interval as needed) + bd.posting_date >= (date_trunc('year', CURRENT_DATE)::date - INTERVAL '1 year') + AND bd.challenge_status::text = 'COMPLETED' + AND bd.registrant_handle IS NOT NULL +GROUP BY + bd.technology_name, + bd.registrant_handle, + bd.registrant_email, + bd.billing_account_id +ORDER BY + "challenge_stats.count_distinct_challenge" DESC +LIMIT 1000; diff --git a/src/app-constants.ts b/src/app-constants.ts index 5ac89a6..3db9434 100644 --- a/src/app-constants.ts +++ b/src/app-constants.ts @@ -5,6 +5,8 @@ export const Scopes = { TopgearCancelledChallenge: "reports:topgear-cancelled-challenge", AllReports: "reports:all", TopgearChallengeTechnology: "reports:topgear-challenge-technology", + TopgearChallengeStatsByUser: "reports:topgear-challenge-stats-by-user", + TopgearChallengeTechnologyByUser: "reports:topgear-challenge-technology-by-user", SFDC: { PaymentsReport: "reports:sfdc-payments", BA: "reports:sfdc-ba", 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..8058133 --- /dev/null +++ b/src/reports/topgear/dtos/challenge-stats-by-user.dto.ts @@ -0,0 +1,18 @@ +import { ApiProperty } from '@nestjs/swagger'; + +export class ChallengeStatsByUserDto { + @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/dtos/challenge-technology-by-user.dto.ts b/src/reports/topgear/dtos/challenge-technology-by-user.dto.ts new file mode 100644 index 0000000..b7c7f98 --- /dev/null +++ b/src/reports/topgear/dtos/challenge-technology-by-user.dto.ts @@ -0,0 +1,24 @@ +import { ApiProperty } from '@nestjs/swagger'; + +export class ChallengeTechnologyByUserDto { + @ApiProperty({ description: 'Name of the challenge technology' }) + challengeTechnologyName: string; + + @ApiProperty({ description: 'Handle of the registrant/user' }) + challengeRegistrantHandle: string; + + @ApiProperty({ description: 'Email of the user' }) + userEmail: string; + + @ApiProperty({ description: 'Billing Account ID' }) + billingAccountID: number; + + @ApiProperty({ description: 'Count of distinct challenges the user participated in' }) + challengeDistinctCount: number; + + @ApiProperty({ description: 'Count of distinct challenges with submissions by the user' }) + submissionByAUser: number; + + @ApiProperty({ description: 'Count of distinct 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 f5a3984..138cac5 100644 --- a/src/reports/topgear/topgear-reports.controller.ts +++ b/src/reports/topgear/topgear-reports.controller.ts @@ -28,6 +28,30 @@ 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, + ) { + return this.reports.getChallengeStatsByUser({ startDate, endDate }); + } + + @Get("challenge-technology-by-user") + @UseGuards(PermissionsGuard) + @Scopes(AppScopes.AllReports, AppScopes.TopgearChallengeTechnologyByUser) + @ApiBearerAuth() + @ApiOperation({ summary: "Get challenge technology per user" }) + async getChallengeTechnologyByUser( + @Query("start_date") startDate?: string, + @Query("end_date") endDate?: string, + ) { + return this.reports.getChallengeTechnologyByUser({ 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 475d6ba..5629102 100644 --- a/src/reports/topgear/topgear-reports.service.ts +++ b/src/reports/topgear/topgear-reports.service.ts @@ -19,6 +19,30 @@ export class TopgearReportsService { return this.db.query(query); } + async getChallengeStatsByUser(opts: { startDate?: string; endDate?: string }) { + 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.toISOString(), endDate.toISOString()]); + } + + async getChallengeTechnologyByUser(opts: { startDate?: string; endDate?: string }) { + 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-technology-by-user.sql"); + return this.db.query(query, [startDate.toISOString(), endDate.toISOString()]); + } + async getChallengesCountBySkill() { const query = this.sql.load("reports/topgear/challenge-count-by-skill.sql"); return this.db.query(query); From b211bcc356df7ac180709798c783698318535cef Mon Sep 17 00:00:00 2001 From: Hentry Martin Date: Tue, 30 Sep 2025 00:06:56 +0200 Subject: [PATCH 2/4] feat: topgear app winner badges report --- sql/reports/topgear/challenge-technology-by-user.sql | 1 - 1 file changed, 1 deletion(-) diff --git a/sql/reports/topgear/challenge-technology-by-user.sql b/sql/reports/topgear/challenge-technology-by-user.sql index a5d693e..1f9c6e3 100644 --- a/sql/reports/topgear/challenge-technology-by-user.sql +++ b/sql/reports/topgear/challenge-technology-by-user.sql @@ -108,7 +108,6 @@ SELECT COUNT(DISTINCT CASE WHEN bd.is_winner THEN bd.challenge_id END) AS "challengeStatsWins" FROM base_data bd WHERE - -- past month for example (adjust interval as needed) bd.posting_date >= (date_trunc('year', CURRENT_DATE)::date - INTERVAL '1 year') AND bd.challenge_status::text = 'COMPLETED' AND bd.registrant_handle IS NOT NULL From 7a46b600460c8770c426e9aace83f5e4dc557e1e Mon Sep 17 00:00:00 2001 From: Hentry Martin Date: Tue, 30 Sep 2025 19:27:10 +0200 Subject: [PATCH 3/4] fix: unified the report --- .../topgear/challenge-stats-by-user.sql | 25 ++++++++++++++----- src/app-constants.ts | 1 - .../dtos/challenge-stats-by-user.dto.ts | 17 ++++++++----- .../dtos/challenge-technology-by-user.dto.ts | 24 ------------------ .../topgear/topgear-reports.controller.ts | 15 ++--------- .../topgear/topgear-reports.service.ts | 23 +++++++---------- 6 files changed, 41 insertions(+), 64 deletions(-) delete mode 100644 src/reports/topgear/dtos/challenge-technology-by-user.dto.ts diff --git a/sql/reports/topgear/challenge-stats-by-user.sql b/sql/reports/topgear/challenge-stats-by-user.sql index 398dd62..6b7cc10 100644 --- a/sql/reports/topgear/challenge-stats-by-user.sql +++ b/sql/reports/topgear/challenge-stats-by-user.sql @@ -56,6 +56,14 @@ registrants AS ( 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, @@ -64,6 +72,7 @@ base_data AS ( 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, @@ -85,22 +94,26 @@ base_data AS ( 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.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" + 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 - "challenge_stats.count_distinct_challenge" DESC + "challengeDistinctCount" DESC LIMIT 1000; diff --git a/src/app-constants.ts b/src/app-constants.ts index 3db9434..8e1911a 100644 --- a/src/app-constants.ts +++ b/src/app-constants.ts @@ -6,7 +6,6 @@ export const Scopes = { AllReports: "reports:all", TopgearChallengeTechnology: "reports:topgear-challenge-technology", TopgearChallengeStatsByUser: "reports:topgear-challenge-stats-by-user", - TopgearChallengeTechnologyByUser: "reports:topgear-challenge-technology-by-user", SFDC: { PaymentsReport: "reports:sfdc-payments", BA: "reports:sfdc-ba", diff --git a/src/reports/topgear/dtos/challenge-stats-by-user.dto.ts b/src/reports/topgear/dtos/challenge-stats-by-user.dto.ts index 8058133..6e94ba2 100644 --- a/src/reports/topgear/dtos/challenge-stats-by-user.dto.ts +++ b/src/reports/topgear/dtos/challenge-stats-by-user.dto.ts @@ -1,18 +1,23 @@ -import { ApiProperty } from '@nestjs/swagger'; +import { ApiProperty } from "@nestjs/swagger"; export class ChallengeStatsByUserDto { - @ApiProperty({ description: 'Handle of the registrant/user' }) + @ApiProperty({ description: "Challenge technology" }) + challengeTechnology: string; + + @ApiProperty({ description: "Handle of the registrant/user" }) challengeRegistrantHandle: string; - @ApiProperty({ description: 'Email of the user' }) + @ApiProperty({ description: "Email of the user" }) userEmail: string; - @ApiProperty({ description: 'Count of distinct challenges the user participated in' }) + @ApiProperty({ + description: "Count of distinct challenges the user participated in", + }) challengeDistinctCount: number; - @ApiProperty({ description: 'Number of submissions made by the user' }) + @ApiProperty({ description: "Number of submissions made by the user" }) submissionByAUser: number; - @ApiProperty({ description: 'Number of challenges won by the user' }) + @ApiProperty({ description: "Number of challenges won by the user" }) challengeStatsWins: number; } diff --git a/src/reports/topgear/dtos/challenge-technology-by-user.dto.ts b/src/reports/topgear/dtos/challenge-technology-by-user.dto.ts deleted file mode 100644 index b7c7f98..0000000 --- a/src/reports/topgear/dtos/challenge-technology-by-user.dto.ts +++ /dev/null @@ -1,24 +0,0 @@ -import { ApiProperty } from '@nestjs/swagger'; - -export class ChallengeTechnologyByUserDto { - @ApiProperty({ description: 'Name of the challenge technology' }) - challengeTechnologyName: string; - - @ApiProperty({ description: 'Handle of the registrant/user' }) - challengeRegistrantHandle: string; - - @ApiProperty({ description: 'Email of the user' }) - userEmail: string; - - @ApiProperty({ description: 'Billing Account ID' }) - billingAccountID: number; - - @ApiProperty({ description: 'Count of distinct challenges the user participated in' }) - challengeDistinctCount: number; - - @ApiProperty({ description: 'Count of distinct challenges with submissions by the user' }) - submissionByAUser: number; - - @ApiProperty({ description: 'Count of distinct 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 138cac5..bbde159 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") @@ -36,22 +37,10 @@ export class TopgearReportsController { async getChallengeStatsByUser( @Query("start_date") startDate?: string, @Query("end_date") endDate?: string, - ) { + ): Promise { return this.reports.getChallengeStatsByUser({ startDate, endDate }); } - @Get("challenge-technology-by-user") - @UseGuards(PermissionsGuard) - @Scopes(AppScopes.AllReports, AppScopes.TopgearChallengeTechnologyByUser) - @ApiBearerAuth() - @ApiOperation({ summary: "Get challenge technology per user" }) - async getChallengeTechnologyByUser( - @Query("start_date") startDate?: string, - @Query("end_date") endDate?: string, - ) { - return this.reports.getChallengeTechnologyByUser({ 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 5629102..7e90e6c 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,7 +20,10 @@ export class TopgearReportsService { return this.db.query(query); } - async getChallengeStatsByUser(opts: { startDate?: string; endDate?: string }) { + 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(); @@ -28,19 +32,10 @@ export class TopgearReportsService { } const query = this.sql.load("reports/topgear/challenge-stats-by-user.sql"); - return this.db.query(query, [startDate.toISOString(), endDate.toISOString()]); - } - - async getChallengeTechnologyByUser(opts: { startDate?: string; endDate?: string }) { - 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-technology-by-user.sql"); - return this.db.query(query, [startDate.toISOString(), endDate.toISOString()]); + return this.db.query(query, [ + startDate.toISOString(), + endDate.toISOString(), + ]); } async getChallengesCountBySkill() { From 5b41921ee22161d88e1501b2948da099573e63fb Mon Sep 17 00:00:00 2001 From: Hentry Martin Date: Tue, 30 Sep 2025 19:28:01 +0200 Subject: [PATCH 4/4] fix: removed unused sql file --- .../topgear/challenge-technology-by-user.sql | 121 ------------------ 1 file changed, 121 deletions(-) delete mode 100644 sql/reports/topgear/challenge-technology-by-user.sql diff --git a/sql/reports/topgear/challenge-technology-by-user.sql b/sql/reports/topgear/challenge-technology-by-user.sql deleted file mode 100644 index 1f9c6e3..0000000 --- a/sql/reports/topgear/challenge-technology-by-user.sql +++ /dev/null @@ -1,121 +0,0 @@ -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.registrant_email, - reg.member_id, - bse.challenge_id, - bse.challenge_status, - prj.group_customer_name, - tech.technology_name, - COALESCE(bil.billing_account_id, prj.project_billing_account_id) AS billing_account_id, - COALESCE( - CASE WHEN bse.challenge_status = 'COMPLETED' THEN lp.last_phase_end END, - bse.planned_end_at, - bse.challenge_created_at - ) AS posting_date, - (sub.best_final_score IS NOT NULL) AS has_submission, - (win.winner_handle = reg.registrant_handle) AS is_winner - 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 "challengeTechnologyName", - bd.registrant_handle AS "challengeRegistrantHandle", - bd.registrant_email AS "userEmail", - bd.billing_account_id AS "billingAccountID", - COUNT(DISTINCT bd.challenge_id) AS "challengeDistinctCount", - COUNT(DISTINCT CASE WHEN bd.has_submission THEN bd.challenge_id END) AS "submissionByAUser", - COUNT(DISTINCT CASE WHEN bd.is_winner THEN bd.challenge_id END) AS "challengeStatsWins" -FROM base_data bd -WHERE - bd.posting_date >= (date_trunc('year', CURRENT_DATE)::date - INTERVAL '1 year') - AND bd.challenge_status::text = 'COMPLETED' - AND bd.registrant_handle IS NOT NULL -GROUP BY - bd.technology_name, - bd.registrant_handle, - bd.registrant_email, - bd.billing_account_id -ORDER BY - "challenge_stats.count_distinct_challenge" DESC -LIMIT 1000;