Skip to content
This repository was archived by the owner on Jan 23, 2025. It is now read-only.

Commit acdca68

Browse files
committed
Merge pull request #357 from Ghost141/srm_api_update
Update search srm challenges api
2 parents b2f8244 + e71f55d commit acdca68

File tree

6 files changed

+66
-37
lines changed

6 files changed

+66
-37
lines changed

actions/srmChallenges.js

Lines changed: 18 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -1,8 +1,8 @@
11
/*
22
* Copyright (C) 2013-2014 TopCoder Inc., All Rights Reserved.
33
*
4-
* @version 1.5
5-
* @author Sky_, freegod, panoptimum
4+
* @version 1.6
5+
* @author Sky_, freegod, panoptimum, Ghost_141
66
* changes in 1.1:
77
* - implement srm API
88
* changes in 1.2:
@@ -20,6 +20,8 @@
2020
* - load round access api
2121
* changes in 1.5
2222
* - added API for retrieving SRM schedule
23+
* Changes in 1.6:
24+
* - Update search srm challenges api to use informixoltp database.
2325
*/
2426
/*jslint node: true, nomen: true */
2527
"use strict";
@@ -177,17 +179,17 @@ exports.searchSRMChallenges = {
177179
description: "searchSRMChallenges",
178180
inputs: {
179181
required: [],
180-
optional: ["pageSize", "pageIndex", "sortColumn", "sortOrder"]
182+
optional: ["pageSize", "pageIndex", "sortColumn", "sortOrder", "listType"]
181183
},
182184
blockedConnectionTypes: [],
183185
outputExample: {},
184186
version: 'v2',
185187
transaction: 'read', // this action is read-only
186-
databases: ["topcoder_dw"],
188+
databases: ["informixoltp"],
187189
run: function (api, connection, next) {
188190
api.log("Execute searchSRMChallenges#run", 'debug');
189-
var helper = api.helper, params = connection.params, sqlParams,
190-
pageIndex, pageSize, sortColumn, sortOrder, error, result,
191+
var helper = api.helper, params = connection.params, sqlParams, listType,
192+
pageIndex, pageSize, sortColumn, sortOrder, error, result, status,
191193
dbConnectionMap = connection.dbConnectionMap;
192194
if (!dbConnectionMap) {
193195
helper.handleNoConnection(api, connection, next);
@@ -202,11 +204,18 @@ exports.searchSRMChallenges = {
202204
}
203205
pageIndex = Number(params.pageIndex || 1);
204206
pageSize = Number(params.pageSize || DEFAULT_PAGE_SIZE);
207+
listType = (params.listType || 'ACTIVE').toUpperCase();
205208

206209
if (!_.isDefined(params.sortOrder) && sortColumn === "roundid") {
207210
sortOrder = "desc";
208211
}
209212

213+
if (listType === helper.ListType.ACTIVE) {
214+
status = 'A';
215+
} else {
216+
status = 'F';
217+
}
218+
210219
async.waterfall([
211220
function (cb) {
212221
var allowedSort = helper.getLowerCaseList(ALLOWABLE_SORT_COLUMN);
@@ -219,6 +228,7 @@ exports.searchSRMChallenges = {
219228
helper.checkPageIndex(pageIndex, "pageIndex") ||
220229
helper.checkPositiveInteger(pageSize, "pageSize") ||
221230
helper.checkContains(["asc", "desc"], sortOrder, "sortOrder") ||
231+
helper.checkContains([helper.ListType.ACTIVE, helper.ListType.UPCOMING], listType, 'listType') ||
222232
helper.checkContains(allowedSort, sortColumn, "sortColumn");
223233
if (error) {
224234
cb(error);
@@ -233,7 +243,8 @@ exports.searchSRMChallenges = {
233243
firstRowIndex: (pageIndex - 1) * pageSize,
234244
pageSize: pageSize,
235245
sortColumn: helper.getSortColumnDBName(sortColumn),
236-
sortOrder: sortOrder
246+
sortOrder: sortOrder,
247+
status: status
237248
};
238249

239250
async.parallel({

apiary.apib

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -6341,7 +6341,7 @@ Request
63416341
### View Algorithm SRM Challenges [GET]
63426342
63436343
+ Parameters
6344-
+ listType (optional, string, `Active`) ... The type of challenges to search. It can only be 'ACTIVE', 'OPEN', 'PAST' or 'UPCOMING'. If it's null, 'Active' will be used.
6344+
+ listType (optional, string, `Active`) ... The type of challenges to search. It can only be 'ACTIVE' or 'UPCOMING'. If it's null, 'Active' will be used.
63456345
+ filter (optional, string, `type`) ... Key of the filter key-value pair
63466346
+ value (optional, string, `Development`) ... Value of the filter key-value pair
63476347
+ pageIndex (optional, number, `1`) ... The paging number, 1-based, -1 if no paging. It can be null.

queries/get_srm_challenges

Lines changed: 40 additions & 21 deletions
Original file line numberDiff line numberDiff line change
@@ -1,22 +1,41 @@
1-
select SKIP @firstRowIndex@ FIRST @pageSize@
2-
r.round_id
3-
,r.short_name AS name
4-
,cal.date AS start_date
5-
,NVL(rd1.num_coders, 0) + NVL(rd2.num_coders, 0) AS total_competitors
6-
,rd1.num_coders AS div_i_competitors
7-
,rd2.num_coders AS div_ii_competitors
8-
,rd1.problems_submitted AS div_i_total_solutions_submitted
9-
,rd2.problems_submitted AS div_ii_total_solutions_submitted
10-
,CASE WHEN rd1.num_coders = 0 THEN 0 ELSE rd1.problems_submitted / rd1.num_coders END::DECIMAL(10,2) AS div_i_average_solutions_submitted
11-
,CASE WHEN rd2.num_coders = 0 THEN 0 ELSE rd2.problems_submitted / rd2.num_coders END::DECIMAL(10,2) AS div_ii_average_solutions_submitted
12-
,rd1.challenges_made_successful AS div_i_total_solutions_challenged
13-
,rd2.challenges_made_successful AS div_ii_total_solutions_challenged
14-
,CASE WHEN rd1.num_coders = 0 THEN 0 ELSE rd1.challenges_made_successful / rd1.num_coders END::DECIMAL(10,2) AS div_i_average_solutions_challenged
15-
,CASE WHEN rd2.num_coders = 0 THEN 0 ELSE rd2.challenges_made_successful / rd2.num_coders END::DECIMAL(10,2) AS div_ii_average_solutions_challenged
16-
FROM contest c
17-
JOIN round AS r ON r.contest_id = c.contest_id AND r.failed = 0 AND r.status='A'
18-
LEFT JOIN round_division AS rd1 ON rd1.division_id = 1 AND rd1.round_id = r.round_id
19-
LEFT JOIN round_division AS rd2 ON rd2.division_id = 2 AND rd2.round_id = r.round_id
20-
JOIN calendar AS cal ON cal.calendar_id = r.calendar_id
21-
WHERE r.round_type_id in (1, 2, 10)
1+
SELECT SKIP @firstRowIndex@ FIRST @pageSize@
2+
r.round_id
3+
, r.name
4+
, rs.start_time AS start_date
5+
, NVL(rd1.div_i_competitors, 0) + NVL(rd2.div_ii_competitors, 0) AS total_competitors
6+
, rd1.div_i_competitors
7+
, rd2.div_ii_competitors
8+
, rd1.div_i_total_solutions_submitted
9+
, rd2.div_ii_total_solutions_submitted
10+
, CASE WHEN rd1.div_i_competitors = 0 THEN 0 ELSE rd1.div_i_total_solutions_submitted / rd1.div_i_competitors END::DECIMAL(10, 2) AS div_i_average_solutions_submitted
11+
, CASE WHEN rd2.div_ii_competitors = 0 THEN 0 ELSE rd2.div_ii_total_solutions_submitted / rd2.div_ii_competitors END::DECIMAL(10, 2) AS div_ii_average_solutions_submitted
12+
, rd1.div_i_total_solutions_challenged
13+
, rd2.div_ii_total_solutions_challenged
14+
, CASE WHEN rd1.div_i_competitors = 0 THEN 0 ELSE rd1.div_i_total_solutions_challenged / rd1.div_i_competitors END::DECIMAL(10, 2) AS div_i_average_solutions_challenged
15+
, CASE WHEN rd2.div_ii_competitors = 0 THEN 0 ELSE rd2.div_ii_total_solutions_challenged / rd2.div_ii_competitors END::DECIMAL(10, 2) AS div_ii_average_solutions_challenged
16+
FROM round r
17+
INNER JOIN round_segment rs ON rs.round_id = r.round_id AND rs.segment_id = 1
18+
LEFT JOIN (
19+
SELECT
20+
rr.round_id
21+
, COUNT(*) AS div_i_competitors
22+
, NVL((SELECT COUNT(*) FROM challenge c WHERE c.status_id <> 92 AND c.round_id = rr.round_id AND c.succeeded = 1), 0) AS div_i_total_solutions_challenged
23+
, NVL((SELECT SUM(CASE WHEN cs.status_id >= 130 THEN 1 ELSE 0 END) FROM component_state cs WHERE cs.round_id = rr.round_id), 0) AS div_i_total_solutions_submitted
24+
FROM room_result rr
25+
INNER JOIN room ON room.room_id = rr.room_id AND room.division_id = 1
26+
GROUP BY rr.round_id
27+
) rd1 ON rd1.round_id = r.round_id
28+
LEFT JOIN (
29+
SELECT
30+
rr.round_id
31+
, COUNT(*) AS div_ii_competitors
32+
, NVL((SELECT COUNT(*) FROM challenge c WHERE c.status_id <> 92 AND c.round_id = rr.round_id AND c.succeeded = 1), 0) AS div_ii_total_solutions_challenged
33+
, NVL((SELECT SUM(CASE WHEN cs.status_id >= 130 THEN 1 ELSE 0 END) FROM component_state cs WHERE cs.round_id = rr.round_id), 0) AS div_ii_total_solutions_submitted
34+
FROM room_result rr
35+
INNER JOIN room ON room.room_id = rr.room_id AND room.division_id = 2
36+
GROUP BY rr.round_id
37+
) rd2 ON rd2.round_id = r.round_id
38+
WHERE r.status = '@status@'
39+
AND r.round_type_id IN (1, 2, 10)
40+
2241
ORDER BY @sortColumn@ @sortOrder@, round_id desc

queries/get_srm_challenges.json

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
11
{
22
"name" : "get_srm_challenges",
3-
"db" : "topcoder_dw",
3+
"db" : "informixoltp",
44
"sqlfile" : "get_srm_challenges"
5-
}
5+
}

queries/get_srm_challenges_count

Lines changed: 3 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,4 @@
11
SELECT COUNT(*) AS total_count
2-
FROM contest AS c
3-
JOIN round r ON c.contest_id = r.contest_id AND r.failed = 0 AND r.status='A'
4-
JOIN calendar AS cal ON cal.calendar_id = r.calendar_id
5-
WHERE r.round_type_id IN (1,2,10)
2+
FROM round r
3+
WHERE r.status = '@status@'
4+
AND r.round_type_id IN (1, 2, 10)
Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
11
{
22
"name" : "get_srm_challenges_count",
3-
"db" : "topcoder_dw",
3+
"db" : "informixoltp",
44
"sqlfile" : "get_srm_challenges_count"
5-
}
5+
}

0 commit comments

Comments
 (0)