Newbie Query question

V

Victoria

I'm fairly new to this, so I could really use a hand.
My query has just 4 columns; StudID, SchoolID, SchoolName, ContestScore.

I need to find the sum of the top 3 scores from each school, then rank these
in descending order. (for schools with < 3 participants, I sum all of their
ContestScores) For example, the data shown below...

100 AD AdamsHigh 75
101 WC WalkerColleg 82
104 AD AdamsHigh 50
106 AD AdamsHigh 75
107 SH SmithSec 100
110 AD AdamsHigh 100
115 WC WalkerColleg 30
119 WC WalkerColleg 70
120 WC WalkerColleg 90

should produce the result...

AdamsHigh 250
WalkerColleg 242
SmithSec 100
 
J

John Spencer

Pardon me, but that could cause problems if there are ties for the third
position. For instance, if the scores for
Adams High (4 records in sample) were all 100, the sum would end up being
400 for the "Top 3" and not 300.

That may or may not be the desired outcome. If the desired outcome is 300
then there is a solution that involves returning different columns in the
subquery.

Post back if you need further details.

--
John Spencer
Access MVP 2002-2005, 2007
Center for Health Program Development and Management
University of Maryland Baltimore County
..
 
A

Allen Browne

John, did you have a suggestion for the article in the web page?

Under "Points to note", it says:
Adding the primary key field to the ORDER BY clause
differentiates between tied values.

Does it need more than that?
 
V

Victoria

Thanks to both John & Allen for responding. Yes, I would like more detail if
that is possible. I'm VERY new at this, so please don't be shy about
providing detail. Thanks so much.
 
J

John Spencer

No, I meant to call the posters attention to the fact that she could be
getting ties returned. I was't sure she had a primary key value in here
table. I guess StudId could be a primary key.

Instead of something like

SELECT T1.SchoolID, SchoolName, Sum(ContestScore) as Total
FROM TableName as T1
WHERE T1.StudID in
(SELECT Top 3 T2.StudID
FROM TableName As T2
WHERE T2.SchoolId = T1.SchoolID
ORDER BY ContestScore Desc, StudID)
GROUP BY SchoolId, SchoolName
ORDER BY Sum(ContestScore)

I was afraid the poster might do

SELECT T1.SchoolID, SchoolName, Sum(ContestScore) as Total
FROM TableName as T1
WHERE T1.ContestScore in
(SELECT Top 3 T2.ContestScore
FROM TableName As T2
WHERE T2.SchoolId = T1.SchoolID
ORDER BY ContestScore Desc, StudID)
GROUP BY SchoolId, SchoolName
ORDER BY Sum(ContestScore)


--
John Spencer
Access MVP 2002-2005, 2007
Center for Health Program Development and Management
University of Maryland Baltimore County
..
 
V

Victoria

John & Allen: Yes, that's it exactly, aside from adding a DESC to the last
ORDER BY. I appreciate the spelled-out examples in this forum. For learners
like me, being able to pick through actual examples is definitely the way to
go!
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Similar Threads

Query 1
Rank query help 3
Query group by Product Name 2
Conditional Formula Question 2
Lookup problem 4
sumif by multiple condition 5
//autoaverage. 2
Word shifts columns automatically 1

Top