From 1f3ff759cbf3c4f2b5e52455bd28bf48a3bc5622 Mon Sep 17 00:00:00 2001 From: TonyJ Date: Mon, 6 Mar 2017 17:58:52 -0500 Subject: [PATCH 1/6] updated queries to exclude tasks that are assigned --- queries/get_active_challenges | 8 ++++++-- queries/get_open_challenges | 6 ++++++ queries/get_open_challenges_count | 4 ++++ queries/get_past_challenges | 8 ++++++++ queries/get_past_challenges_count | 4 ++++ queries/get_upcoming_challenges | 5 ++++- 6 files changed, 32 insertions(+), 3 deletions(-) diff --git a/queries/get_active_challenges b/queries/get_active_challenges index c172d49cc..94e2c25b5 100644 --- a/queries/get_active_challenges +++ b/queries/get_active_challenges @@ -44,6 +44,7 @@ FROM project p , outer project_info pi4 --forum id , outer project_info pi79 , project_info pi1 -- external id +, OUTER project_info pi82 WHERE p.project_status_id = pstatus.project_status_id AND p.project_id = pn.project_id AND pn.project_info_type_id = 6 @@ -70,5 +71,8 @@ AND pcl.project_category_id NOT IN (27, 37) --exclude when spec review was a 'co AND pp1.phase_status_id IN (2, 3) AND pi1.project_info_type_id = 1 -- external reference id AND pi1.project_id = p.project_id - -ORDER BY @sort_column@ @sort_order@ +AND pi82.project_id = p.project_id +AND pi82.project_info_type_id = 82 +AND NOT ( NVL(pi82.value,0) = 1 + AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 + ) ORDER BY @sort_column@ @sort_order@ diff --git a/queries/get_open_challenges b/queries/get_open_challenges index 47ff4ee5f..26a94609a 100644 --- a/queries/get_open_challenges +++ b/queries/get_open_challenges @@ -70,6 +70,7 @@ FROM project p , outer project_info pi4 --forum id , outer project_info pi79 , project_info pi1 -- external id +, OUTER project_info pi82 WHERE p.project_status_id = pstatus.project_status_id AND p.project_id = pn.project_id AND pn.project_info_type_id = 6 @@ -102,5 +103,10 @@ AND pn.value LIKE ('@challenge_name@') AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) >= @prize_lower_bound@ AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) <= @prize_upper_bound@ AND p.tc_direct_project_id = DECODE(@project_id@, 0, p.tc_direct_project_id, @project_id@) +AND pi82.project_id = p.project_id +AND pi82.project_info_type_id = 82 +AND NOT ( NVL(pi82.value,0) = 1 + AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 + ) ORDER BY @sort_column@ @sort_order@ ) diff --git a/queries/get_open_challenges_count b/queries/get_open_challenges_count index 16798c55a..5e26f7d47 100644 --- a/queries/get_open_challenges_count +++ b/queries/get_open_challenges_count @@ -5,6 +5,7 @@ FROM project p , project_info pn , project_category_lu pcl , project_info pi1 +, OUTER project_info pi82 WHERE 1=1 AND p.project_id = pn.project_id AND pn.project_info_type_id = 6 @@ -32,3 +33,6 @@ AND pn.value LIKE ('@challenge_name@') AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) >= @prize_lower_bound@ AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) <= @prize_upper_bound@ AND p.tc_direct_project_id = DECODE(@project_id@, 0, p.tc_direct_project_id, @project_id@) +AND NOT ( NVL(pi82.value,0) = 1 + AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 + ) diff --git a/queries/get_past_challenges b/queries/get_past_challenges index 45c1668c2..333454aea 100644 --- a/queries/get_past_challenges +++ b/queries/get_past_challenges @@ -59,6 +59,11 @@ INNER JOIN project_info pn ON pn.project_id = p.project_id AND pn.project_info_t INNER JOIN project_info pi1 ON pi1.project_id = p.project_id AND pi1.project_info_type_id = 1 LEFT JOIN project_phase pp15 ON pp15.project_id = p.project_id AND pp15.phase_type_id = 15 LEFT JOIN project_info pidr ON pidr.project_id = p.project_id AND pidr.project_info_type_id = 26 +LEFT OUTER JOIN + project_info pi82 +ON + pi82.project_id = p.project_id +AND pi82.project_info_type_id = 82 WHERE p.project_status_id IN (4, 5, 6, 7, 8, 9, 10, 11) AND pcl.project_category_id NOT IN (27, 37) AND pcl.project_type_id IN (@track@) @@ -71,5 +76,8 @@ AND LOWER(pn.value) LIKE('@challenge_name@') AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) >= @prize_lower_bound@ AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) <= @prize_upper_bound@ AND p.tc_direct_project_id = DECODE(@project_id@, 0, p.tc_direct_project_id, @project_id@) +AND NOT ( NVL(pi82.value,0) = 1 + AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 + ) ORDER BY @sort_column@ @sort_order@ ) diff --git a/queries/get_past_challenges_count b/queries/get_past_challenges_count index c3f343bc5..d278a1002 100644 --- a/queries/get_past_challenges_count +++ b/queries/get_past_challenges_count @@ -5,6 +5,7 @@ FROM project p , project_info pn , project_info pi1 , project_category_lu pcl +, OUTER project_info pi82 WHERE p.project_id = pn.project_id AND pn.project_info_type_id = 6 AND pp1.project_id = p.project_id @@ -32,3 +33,6 @@ AND (not exists (select contest_id from contest_eligibility where contest_id = p or exists(select contest_id from contest_eligibility ce, group_contest_eligibility gce, user_group_xref x where x.login_id = @user_id@ AND x.group_id = gce.group_id AND gce.contest_eligibility_id = ce.contest_eligibility_id AND ce.contest_id = p.project_id)) +AND NOT ( NVL(pi82.value,0) = 1 + AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 + ) diff --git a/queries/get_upcoming_challenges b/queries/get_upcoming_challenges index 30f5bcaf2..1e3fd47c6 100644 --- a/queries/get_upcoming_challenges +++ b/queries/get_upcoming_challenges @@ -36,6 +36,7 @@ FROM project p , outer project_info pi4 --forum id , outer project_info pi79 , project_info pi1 -- external id +, OUTER project_info pi82 WHERE p.project_status_id = pstatus.project_status_id AND p.project_id = pn.project_id AND pn.project_info_type_id = 6 @@ -67,5 +68,7 @@ AND pp1.scheduled_start_time > CURRENT AND pp1.scheduled_start_time < CURRENT + 90 UNITS DAY AND pi1.project_info_type_id = 1 -- external reference id AND pi1.project_id = p.project_id - +AND NOT ( NVL(pi82.value,0) = 1 + AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 + ) ORDER BY @sort_column@ @sort_order@ From 3e136ac438c1875a8f9719df761f5401b216b73a Mon Sep 17 00:00:00 2001 From: TonyJ Date: Mon, 6 Mar 2017 18:22:54 -0500 Subject: [PATCH 2/6] updated queries to exclude tasks that are assigned --- queries/get_active_challenges | 8 ++------ queries/get_open_challenges | 7 +------ queries/get_past_challenges | 9 +-------- queries/get_upcoming_challenges | 5 +---- 4 files changed, 5 insertions(+), 24 deletions(-) diff --git a/queries/get_active_challenges b/queries/get_active_challenges index 94e2c25b5..81779a980 100644 --- a/queries/get_active_challenges +++ b/queries/get_active_challenges @@ -44,7 +44,6 @@ FROM project p , outer project_info pi4 --forum id , outer project_info pi79 , project_info pi1 -- external id -, OUTER project_info pi82 WHERE p.project_status_id = pstatus.project_status_id AND p.project_id = pn.project_id AND pn.project_info_type_id = 6 @@ -71,8 +70,5 @@ AND pcl.project_category_id NOT IN (27, 37) --exclude when spec review was a 'co AND pp1.phase_status_id IN (2, 3) AND pi1.project_info_type_id = 1 -- external reference id AND pi1.project_id = p.project_id -AND pi82.project_id = p.project_id -AND pi82.project_info_type_id = 82 -AND NOT ( NVL(pi82.value,0) = 1 - AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 - ) ORDER BY @sort_column@ @sort_order@ +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82) -- exclude assigned tasks +ORDER BY @sort_column@ @sort_order@ diff --git a/queries/get_open_challenges b/queries/get_open_challenges index 26a94609a..b585f222a 100644 --- a/queries/get_open_challenges +++ b/queries/get_open_challenges @@ -70,7 +70,6 @@ FROM project p , outer project_info pi4 --forum id , outer project_info pi79 , project_info pi1 -- external id -, OUTER project_info pi82 WHERE p.project_status_id = pstatus.project_status_id AND p.project_id = pn.project_id AND pn.project_info_type_id = 6 @@ -103,10 +102,6 @@ AND pn.value LIKE ('@challenge_name@') AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) >= @prize_lower_bound@ AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) <= @prize_upper_bound@ AND p.tc_direct_project_id = DECODE(@project_id@, 0, p.tc_direct_project_id, @project_id@) -AND pi82.project_id = p.project_id -AND pi82.project_info_type_id = 82 -AND NOT ( NVL(pi82.value,0) = 1 - AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 - ) +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82) -- exclude assigned tasks ORDER BY @sort_column@ @sort_order@ ) diff --git a/queries/get_past_challenges b/queries/get_past_challenges index 333454aea..9cdacad71 100644 --- a/queries/get_past_challenges +++ b/queries/get_past_challenges @@ -59,11 +59,6 @@ INNER JOIN project_info pn ON pn.project_id = p.project_id AND pn.project_info_t INNER JOIN project_info pi1 ON pi1.project_id = p.project_id AND pi1.project_info_type_id = 1 LEFT JOIN project_phase pp15 ON pp15.project_id = p.project_id AND pp15.phase_type_id = 15 LEFT JOIN project_info pidr ON pidr.project_id = p.project_id AND pidr.project_info_type_id = 26 -LEFT OUTER JOIN - project_info pi82 -ON - pi82.project_id = p.project_id -AND pi82.project_info_type_id = 82 WHERE p.project_status_id IN (4, 5, 6, 7, 8, 9, 10, 11) AND pcl.project_category_id NOT IN (27, 37) AND pcl.project_type_id IN (@track@) @@ -76,8 +71,6 @@ AND LOWER(pn.value) LIKE('@challenge_name@') AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) >= @prize_lower_bound@ AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) <= @prize_upper_bound@ AND p.tc_direct_project_id = DECODE(@project_id@, 0, p.tc_direct_project_id, @project_id@) -AND NOT ( NVL(pi82.value,0) = 1 - AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 - ) +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82) -- exclude assigned tasks ORDER BY @sort_column@ @sort_order@ ) diff --git a/queries/get_upcoming_challenges b/queries/get_upcoming_challenges index 1e3fd47c6..0f026ebbb 100644 --- a/queries/get_upcoming_challenges +++ b/queries/get_upcoming_challenges @@ -36,7 +36,6 @@ FROM project p , outer project_info pi4 --forum id , outer project_info pi79 , project_info pi1 -- external id -, OUTER project_info pi82 WHERE p.project_status_id = pstatus.project_status_id AND p.project_id = pn.project_id AND pn.project_info_type_id = 6 @@ -68,7 +67,5 @@ AND pp1.scheduled_start_time > CURRENT AND pp1.scheduled_start_time < CURRENT + 90 UNITS DAY AND pi1.project_info_type_id = 1 -- external reference id AND pi1.project_id = p.project_id -AND NOT ( NVL(pi82.value,0) = 1 - AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 - ) +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82) -- exclude assigned tasks ORDER BY @sort_column@ @sort_order@ From 873749141f54539fd5ccbd350ce408f55210d1f7 Mon Sep 17 00:00:00 2001 From: ajefts Date: Tue, 7 Mar 2017 16:35:11 -0500 Subject: [PATCH 3/6] added task check --- queries/get_past_challenges_count | 102 ++++++++++++++++++++---------- 1 file changed, 70 insertions(+), 32 deletions(-) diff --git a/queries/get_past_challenges_count b/queries/get_past_challenges_count index d278a1002..9cdacad71 100644 --- a/queries/get_past_challenges_count +++ b/queries/get_past_challenges_count @@ -1,38 +1,76 @@ -SELECT COUNT(*) AS total +SELECT is_studio +, challenge_type +, challenge_name +, challenge_id +, (SELECT value FROM project_info WHERE project_id = challenge_id AND project_info_type_id = 4) AS forum_id +, num_submissions +, num_registrants +, number_of_checkpoints_prizes +, first_place_prize +, total_prize +, checkpoint_total_prizes +, registration_start_date +, registration_end_date +, checkpoint_submission_end_date +, submission_end_date +, status +, digital_run_points +, nvl((SELECT MAX(event_id) FROM contest_project_xref x, contest c WHERE project_id = challenge_id AND c.contest_id = x.contest_id), 0) AS event_id +, (SELECT event_short_desc FROM event e WHERE e.event_id = nvl((SELECT MAX(event_id) FROM contest_project_xref x, contest c WHERE project_id = challenge_id AND c.contest_id = x.contest_id), 0)) AS event_name +, technology_list(value_for_technology) AS technologies +, platform_list(id_for_platform) AS platforms +, registration_open +, NVL((SELECT CAST('t' AS boolean) FROM contest_eligibility WHERE contest_id = challenge_id), CAST('f' AS boolean)) AS is_private +, (SELECT value FROM project_info pi53 WHERE project_id = challenge_id AND project_info_type_id = 53) AS submissions_viewable +FROM ( +SELECT +SKIP @first_row_index@ +FIRST @page_size@ + CASE WHEN (p.project_studio_spec_id IS NOT NULL) THEN 1 ELSE 0 END AS is_studio +, pcl.description AS challenge_type +, pn.value AS challenge_name +, p.project_id AS challenge_id +, (SELECT COUNT(*) FROM submission s1 INNER JOIN upload u1 ON s1.upload_id = u1.upload_id + WHERE u1.project_id = p.project_id + AND s1.submission_type_id = 1 + AND s1.submission_status_id <> 5) AS num_submissions +, (SELECT COUNT(*) FROM resource r WHERE r.project_id = p.project_id AND r.resource_role_id = 1) AS num_registrants +, NVL((SELECT SUM(pr.number_of_submissions) FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 14), 0) AS number_of_checkpoints_prizes +, (SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1) AS first_place_prize +, (SELECT SUM(prize_amount) FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15) AS total_prize +, (SELECT SUM(prize_amount * number_of_submissions) FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 14) AS checkpoint_total_prizes +, NVL(pp1.actual_start_time, pp1.scheduled_start_time) AS registration_start_date +, NVL(pp1.actual_end_time, pp1.scheduled_end_time) AS registration_end_date +, NVL(pp15.actual_end_time, pp15.scheduled_end_time) AS checkpoint_submission_end_date +, NVL(pp2.actual_end_time, pp2.scheduled_end_time) AS submission_end_date +, pstatus.name AS status +, CASE WHEN pidr.value = 'On' THEN + NVL((SELECT value::decimal FROM project_info pi_dr WHERE pi_dr.project_info_type_id = 30 AND pi_dr.project_id = p.project_id), (SELECT round(NVL(pi16.value::decimal, 0)) FROM project_info pi16 WHERE pi16.project_info_type_id = 16 AND pi16.project_id = p.project_id)) + ELSE NULL END AS digital_run_points +, pi1.value AS value_for_technology +, p.project_id AS id_for_platform +, CASE WHEN (pp1.phase_status_id = 2) THEN 'Yes' ELSE 'No' END AS registration_open FROM project p -, project_phase pp1 --registration phase -, project_phase pp2 --submission phase -, project_info pn -, project_info pi1 -, project_category_lu pcl -, OUTER project_info pi82 -WHERE p.project_id = pn.project_id -AND pn.project_info_type_id = 6 -AND pp1.project_id = p.project_id -AND pp1.phase_type_id = 1 --registration phase -AND pp2.project_id = p.project_id -AND pp2.phase_type_id = 2 --submission phase -AND p.project_category_id = pcl.project_category_id -AND p.project_status_id IN (4, 5, 6, 7, 8, 9, 10, 11) -AND pcl.project_type_id IN (@track@) -AND pp1.phase_status_id in (2,3) -AND pi1.project_id = p.project_id -AND pi1.project_info_type_id = 1 +INNER JOIN project_status_lu pstatus ON pstatus.project_status_id = p.project_status_id +INNER JOIN project_category_lu pcl ON pcl.project_category_id = p.project_category_id +INNER JOIN project_phase pp1 ON pp1.project_id = p.project_id AND pp1.phase_type_id = 1 +INNER JOIN project_phase pp2 ON pp2.project_id = p.project_id AND pp2.phase_type_id = 2 +INNER JOIN project_info pn ON pn.project_id = p.project_id AND pn.project_info_type_id = 6 +INNER JOIN project_info pi1 ON pi1.project_id = p.project_id AND pi1.project_info_type_id = 1 +LEFT JOIN project_phase pp15 ON pp15.project_id = p.project_id AND pp15.phase_type_id = 15 +LEFT JOIN project_info pidr ON pidr.project_id = p.project_id AND pidr.project_info_type_id = 26 +WHERE +p.project_status_id IN (4, 5, 6, 7, 8, 9, 10, 11) +AND pcl.project_category_id NOT IN (27, 37) AND pcl.project_type_id IN (@track@) and NVL(pp2.actual_end_time, pp2.scheduled_end_time) > '2012-01-01 00:00:00' -AND pcl.project_category_id NOT IN (27, 37) --exclude when spec review was a 'contest.' Also exclude MM, which is in there as a 'software' contest. --- start of parameters - AND NVL(pp2.actual_end_time, pp2.scheduled_end_time) BETWEEN TO_DATE('@submission_end_from@ 00:00:00', '%Y-%m-%d %H:%M:%S') AND TO_DATE('@submission_end_to@ 23:59:59', '%Y-%m-%d %H:%M:%S') - -AND LOWER(pn.value) LIKE ('@challenge_name@') +-- Filter out the challenge that user is not belong to. +AND pp1.phase_status_id in (2,3) +AND LOWER(pn.value) LIKE('@challenge_name@') +-- start of parameters AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) >= @prize_lower_bound@ AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) <= @prize_upper_bound@ AND p.tc_direct_project_id = DECODE(@project_id@, 0, p.tc_direct_project_id, @project_id@) --- Filter out the challenge that user is not belong to. -AND (not exists (select contest_id from contest_eligibility where contest_id = p.project_id) - or exists(select contest_id from contest_eligibility ce, group_contest_eligibility gce, user_group_xref x - where x.login_id = @user_id@ AND x.group_id = gce.group_id AND gce.contest_eligibility_id = ce.contest_eligibility_id - AND ce.contest_id = p.project_id)) -AND NOT ( NVL(pi82.value,0) = 1 - AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 - ) +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82) -- exclude assigned tasks +ORDER BY @sort_column@ @sort_order@ +) From a807107e3adf29dbcfb54e0fa0da616d75571e24 Mon Sep 17 00:00:00 2001 From: TonyJ Date: Sat, 11 Mar 2017 09:25:31 -0500 Subject: [PATCH 4/6] fixed bug in task exclusion --- queries/get_active_challenges | 2 +- queries/get_open_challenges | 2 +- queries/get_past_challenges | 2 +- queries/get_upcoming_challenges | 2 +- 4 files changed, 4 insertions(+), 4 deletions(-) diff --git a/queries/get_active_challenges b/queries/get_active_challenges index 81779a980..cd17225db 100644 --- a/queries/get_active_challenges +++ b/queries/get_active_challenges @@ -70,5 +70,5 @@ AND pcl.project_category_id NOT IN (27, 37) --exclude when spec review was a 'co AND pp1.phase_status_id IN (2, 3) AND pi1.project_info_type_id = 1 -- external reference id AND pi1.project_id = p.project_id -AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82) -- exclude assigned tasks +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82 and pi82.value = 1) -- exclude assigned tasks ORDER BY @sort_column@ @sort_order@ diff --git a/queries/get_open_challenges b/queries/get_open_challenges index b585f222a..7a581d5f9 100644 --- a/queries/get_open_challenges +++ b/queries/get_open_challenges @@ -102,6 +102,6 @@ AND pn.value LIKE ('@challenge_name@') AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) >= @prize_lower_bound@ AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) <= @prize_upper_bound@ AND p.tc_direct_project_id = DECODE(@project_id@, 0, p.tc_direct_project_id, @project_id@) -AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82) -- exclude assigned tasks +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82 and pi82.value = 1) -- exclude assigned tasks ORDER BY @sort_column@ @sort_order@ ) diff --git a/queries/get_past_challenges b/queries/get_past_challenges index 9cdacad71..49ff02fcf 100644 --- a/queries/get_past_challenges +++ b/queries/get_past_challenges @@ -71,6 +71,6 @@ AND LOWER(pn.value) LIKE('@challenge_name@') AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) >= @prize_lower_bound@ AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) <= @prize_upper_bound@ AND p.tc_direct_project_id = DECODE(@project_id@, 0, p.tc_direct_project_id, @project_id@) -AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82) -- exclude assigned tasks +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82 and pi82.value = 1) -- exclude assigned tasks ORDER BY @sort_column@ @sort_order@ ) diff --git a/queries/get_upcoming_challenges b/queries/get_upcoming_challenges index 0f026ebbb..585acf7a7 100644 --- a/queries/get_upcoming_challenges +++ b/queries/get_upcoming_challenges @@ -67,5 +67,5 @@ AND pp1.scheduled_start_time > CURRENT AND pp1.scheduled_start_time < CURRENT + 90 UNITS DAY AND pi1.project_info_type_id = 1 -- external reference id AND pi1.project_id = p.project_id -AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82) -- exclude assigned tasks +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82 and pi82.value = 1) -- exclude assigned tasks ORDER BY @sort_column@ @sort_order@ From 1d3c3649f2a9eccf80eb247340acdf7ab0d5772b Mon Sep 17 00:00:00 2001 From: TonyJ Date: Sat, 11 Mar 2017 09:34:15 -0500 Subject: [PATCH 5/6] fixed bug in task exclusion --- queries/get_past_challenges_count | 99 +++++++++---------------------- 1 file changed, 29 insertions(+), 70 deletions(-) diff --git a/queries/get_past_challenges_count b/queries/get_past_challenges_count index 9cdacad71..12b383a68 100644 --- a/queries/get_past_challenges_count +++ b/queries/get_past_challenges_count @@ -1,76 +1,35 @@ -SELECT is_studio -, challenge_type -, challenge_name -, challenge_id -, (SELECT value FROM project_info WHERE project_id = challenge_id AND project_info_type_id = 4) AS forum_id -, num_submissions -, num_registrants -, number_of_checkpoints_prizes -, first_place_prize -, total_prize -, checkpoint_total_prizes -, registration_start_date -, registration_end_date -, checkpoint_submission_end_date -, submission_end_date -, status -, digital_run_points -, nvl((SELECT MAX(event_id) FROM contest_project_xref x, contest c WHERE project_id = challenge_id AND c.contest_id = x.contest_id), 0) AS event_id -, (SELECT event_short_desc FROM event e WHERE e.event_id = nvl((SELECT MAX(event_id) FROM contest_project_xref x, contest c WHERE project_id = challenge_id AND c.contest_id = x.contest_id), 0)) AS event_name -, technology_list(value_for_technology) AS technologies -, platform_list(id_for_platform) AS platforms -, registration_open -, NVL((SELECT CAST('t' AS boolean) FROM contest_eligibility WHERE contest_id = challenge_id), CAST('f' AS boolean)) AS is_private -, (SELECT value FROM project_info pi53 WHERE project_id = challenge_id AND project_info_type_id = 53) AS submissions_viewable -FROM ( -SELECT -SKIP @first_row_index@ -FIRST @page_size@ - CASE WHEN (p.project_studio_spec_id IS NOT NULL) THEN 1 ELSE 0 END AS is_studio -, pcl.description AS challenge_type -, pn.value AS challenge_name -, p.project_id AS challenge_id -, (SELECT COUNT(*) FROM submission s1 INNER JOIN upload u1 ON s1.upload_id = u1.upload_id - WHERE u1.project_id = p.project_id - AND s1.submission_type_id = 1 - AND s1.submission_status_id <> 5) AS num_submissions -, (SELECT COUNT(*) FROM resource r WHERE r.project_id = p.project_id AND r.resource_role_id = 1) AS num_registrants -, NVL((SELECT SUM(pr.number_of_submissions) FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 14), 0) AS number_of_checkpoints_prizes -, (SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1) AS first_place_prize -, (SELECT SUM(prize_amount) FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15) AS total_prize -, (SELECT SUM(prize_amount * number_of_submissions) FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 14) AS checkpoint_total_prizes -, NVL(pp1.actual_start_time, pp1.scheduled_start_time) AS registration_start_date -, NVL(pp1.actual_end_time, pp1.scheduled_end_time) AS registration_end_date -, NVL(pp15.actual_end_time, pp15.scheduled_end_time) AS checkpoint_submission_end_date -, NVL(pp2.actual_end_time, pp2.scheduled_end_time) AS submission_end_date -, pstatus.name AS status -, CASE WHEN pidr.value = 'On' THEN - NVL((SELECT value::decimal FROM project_info pi_dr WHERE pi_dr.project_info_type_id = 30 AND pi_dr.project_id = p.project_id), (SELECT round(NVL(pi16.value::decimal, 0)) FROM project_info pi16 WHERE pi16.project_info_type_id = 16 AND pi16.project_id = p.project_id)) - ELSE NULL END AS digital_run_points -, pi1.value AS value_for_technology -, p.project_id AS id_for_platform -, CASE WHEN (pp1.phase_status_id = 2) THEN 'Yes' ELSE 'No' END AS registration_open +SELECT COUNT(*) AS total FROM project p -INNER JOIN project_status_lu pstatus ON pstatus.project_status_id = p.project_status_id -INNER JOIN project_category_lu pcl ON pcl.project_category_id = p.project_category_id -INNER JOIN project_phase pp1 ON pp1.project_id = p.project_id AND pp1.phase_type_id = 1 -INNER JOIN project_phase pp2 ON pp2.project_id = p.project_id AND pp2.phase_type_id = 2 -INNER JOIN project_info pn ON pn.project_id = p.project_id AND pn.project_info_type_id = 6 -INNER JOIN project_info pi1 ON pi1.project_id = p.project_id AND pi1.project_info_type_id = 1 -LEFT JOIN project_phase pp15 ON pp15.project_id = p.project_id AND pp15.phase_type_id = 15 -LEFT JOIN project_info pidr ON pidr.project_id = p.project_id AND pidr.project_info_type_id = 26 -WHERE -p.project_status_id IN (4, 5, 6, 7, 8, 9, 10, 11) -AND pcl.project_category_id NOT IN (27, 37) AND pcl.project_type_id IN (@track@) -and NVL(pp2.actual_end_time, pp2.scheduled_end_time) > '2012-01-01 00:00:00' -AND NVL(pp2.actual_end_time, pp2.scheduled_end_time) BETWEEN TO_DATE('@submission_end_from@ 00:00:00', '%Y-%m-%d %H:%M:%S') AND TO_DATE('@submission_end_to@ 23:59:59', '%Y-%m-%d %H:%M:%S') --- Filter out the challenge that user is not belong to. +, project_phase pp1 --registration phase +, project_phase pp2 --submission phase +, project_info pn +, project_info pi1 +, project_category_lu pcl +WHERE p.project_id = pn.project_id +AND pn.project_info_type_id = 6 +AND pp1.project_id = p.project_id +AND pp1.phase_type_id = 1 --registration phase +AND pp2.project_id = p.project_id +AND pp2.phase_type_id = 2 --submission phase +AND p.project_category_id = pcl.project_category_id +AND p.project_status_id IN (4, 5, 6, 7, 8, 9, 10, 11) +AND pcl.project_type_id IN (@track@) AND pp1.phase_status_id in (2,3) -AND LOWER(pn.value) LIKE('@challenge_name@') +AND pi1.project_id = p.project_id +AND pi1.project_info_type_id = 1 +and NVL(pp2.actual_end_time, pp2.scheduled_end_time) > '2012-01-01 00:00:00' +AND pcl.project_category_id NOT IN (27, 37) --exclude when spec review was a 'contest.' Also exclude MM, which is in there as a 'software' contest. -- start of parameters + +AND NVL(pp2.actual_end_time, pp2.scheduled_end_time) BETWEEN TO_DATE('@submission_end_from@ 00:00:00', '%Y-%m-%d %H:%M:%S') AND TO_DATE('@submission_end_to@ 23:59:59', '%Y-%m-%d %H:%M:%S') + +AND LOWER(pn.value) LIKE ('@challenge_name@') AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) >= @prize_lower_bound@ AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) <= @prize_upper_bound@ AND p.tc_direct_project_id = DECODE(@project_id@, 0, p.tc_direct_project_id, @project_id@) -AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82) -- exclude assigned tasks -ORDER BY @sort_column@ @sort_order@ -) +-- Filter out the challenge that user is not belong to. +AND (not exists (select contest_id from contest_eligibility where contest_id = p.project_id) + or exists(select contest_id from contest_eligibility ce, group_contest_eligibility gce, user_group_xref x + where x.login_id = @user_id@ AND x.group_id = gce.group_id AND gce.contest_eligibility_id = ce.contest_eligibility_id + AND ce.contest_id = p.project_id)) +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82 and pi82.value = 1) -- exclude assigned tasks \ No newline at end of file From 582855083377ec4dc065d40490369dc3458f3a15 Mon Sep 17 00:00:00 2001 From: TonyJ Date: Sat, 11 Mar 2017 09:35:09 -0500 Subject: [PATCH 6/6] fixed bug in task exclusion --- queries/get_open_challenges_count | 5 +---- 1 file changed, 1 insertion(+), 4 deletions(-) diff --git a/queries/get_open_challenges_count b/queries/get_open_challenges_count index 5e26f7d47..52cc31b2d 100644 --- a/queries/get_open_challenges_count +++ b/queries/get_open_challenges_count @@ -5,7 +5,6 @@ FROM project p , project_info pn , project_category_lu pcl , project_info pi1 -, OUTER project_info pi82 WHERE 1=1 AND p.project_id = pn.project_id AND pn.project_info_type_id = 6 @@ -33,6 +32,4 @@ AND pn.value LIKE ('@challenge_name@') AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) >= @prize_lower_bound@ AND NVL((SELECT pr.prize_amount FROM prize pr WHERE pr.project_id = p.project_id AND pr.prize_type_id = 15 AND pr.place = 1), 0) <= @prize_upper_bound@ AND p.tc_direct_project_id = DECODE(@project_id@, 0, p.tc_direct_project_id, @project_id@) -AND NOT ( NVL(pi82.value,0) = 1 - AND (select count(*) from resource r where r.project_id = p.project_id and resource_role_id = 1 ) > 0 - ) +AND not exists (select 1 from resource r, project_info pi82 where r.project_id = p.project_id and r.resource_role_id = 1 and p.project_id = pi82.project_id and project_info_type_id = 82 and pi82.value = 1) -- exclude assigned tasks