Finding top ten records for each Name

maic15

Active Member
Joined
Nov 17, 2004
Messages
313
I'm trying to find the top ten records for data that has more than 10 records for each name.. For example,

PCP DOS
John
1/5/2006
1/6/2006
1/7/2006
1/8/2006
1/9/2006
1/10/2006
1/11/2006
1/12/2006
1/13/2006
1/14/2006

Tom
2/12/2004
2/13/2004
2/14/2004
2/15/2004
2/16/2004
2/17/2004
2/18/2004
2/19/2004

Ideas?
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
Hi, you can do this with a select query provided your table has both the name and date in each row.

Create a new query, add the relevant table, view totals, add the name (sort ascending) and date (sort descending) fields to your query, right click the table -> properties -> change the table alias to a new name (e.g. "tblAlias" without the quotes), add a third field to your query, as follows :

Rank: (Select Count(*) from tblMaic Where ([PCP]=tblAlias.[PCP]) and ([DOS]> tblAlias.[DOS]))+1

Change "Group By" to "Expression" and add the following to the criteria of the rank field : "<=10" (without the quotes).

Please note that I used "tblAlias" as the Table Alias for the table I called "tblMaic", and I used the field names "PCP" and "DOS" (per your example). Make sure you change the table and alias and field(?) names to reflect the actual names you are using.

The SQL for the query follows :

SELECT tblAlias.PCP, tblAlias.DOS, (Select Count(*) from tblMaic Where ([PCP]=tblAlias.[PCP]) and ([DOS]> tblAlias.[DOS]))+1 AS Rank
FROM tblMaic AS tblAlias
GROUP BY tblAlias.PCP, tblAlias.DOS
HAVING ((((Select Count(*) from tblMaic Where ([PCP]=tblAlias.[PCP]) and ([DOS]> tblAlias.[DOS]))+1)<=10))
ORDER BY tblAlias.PCP, tblAlias.DOS DESC;

HTH, Andrew. :)
 
Upvote 0

Forum statistics

Threads
1,215,453
Messages
6,124,925
Members
449,195
Latest member
Stevenciu

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top