ACC2000: How to Rank Records Within a Query

ID: Q208946


The information in this article applies to:
  • Microsoft Access 2000

Advanced: Requires expert coding, interoperability, and multiuser skills.


SUMMARY

This article has three examples that show you how to rank records within a query. The first example ranks records from a table. The second example ranks the results of a totals query. The third example demonstrates an alternative method of handling ties in ranking.

All the examples in this article require a field that has a value that can be evaluated using either the Greater Than (>) or the Less Than (<) operator, and a subquery to count the number of records that are greater than or less than the current record.


MORE INFORMATION

In Example 1 and Example 2 below, records following a tie in ranking are given the same rank number they would have received had there been no tie. The following table demonstrates a sample result with a tie in ranking:

Salesperson Sales Rank
Peterson $8000 1
Wakita $7000 2
Akerley $7000 2
Reston $6000 4
In Example 3 below, a second query, which has a DISTINCT clause, is used to return a unique list of ranking less than that of the current record. The following table, using the same records as the table above, demonstrates the results of this method:
Salesperson Sales Rank
Peterson $8000 1
Wakita $7000 2
Akerley $7000 2
Reston $6000 3

Example 1

This example returns results that show the order in which employees were hired.

CAUTION: Following the steps in this example will modify the sample database Northwind.mdb. You may want to back up the Northwind.mdb file and perform these steps on a copy of the database.

  1. Open the sample Northwind.mdb and create a new query based on the Employees table.


  2. If the property sheet is not displayed, click Properties button on the toolbar.


  3. Click the title bar of the Employees field list, and then set the field list's Alias property to Emp1.


  4. Drag the LastName and HireDate fields from the field list to the query grid.


  5. In the Sort row of the HireDate column, select Ascending.


  6. In the Field row of the third column, enter the following expression:


  7. 
       Seniority: (Select Count(*) from Employees Where [HireDate] < _
       [Emp1].[HireDate];) 
  8. Run the query. Note that the returned records are ranked sequentially starting at 0. The subquery returns the number of employees hired before the current employee. To rank the records starting with 1, use the following expression in step 6 above:


  9. 
       Seniority: (Select Count(*) from Employees Where [HireDate] < _ 
       [Emp1].[HireDate]+1;) 
  10. To see the results of a tie in ranking, change the hire date of any employee to match another (in the Employees table).


Example 2

This example returns results that rank categories by the number of products in each category.

CAUTION: Following the steps in this example will modify the sample database Northwind.mdb. You may want to back up the Northwind.mdb file and perform these steps on a copy of the database.

  1. Create a new query based on the Products table.


  2. Drag the CategoryID and ProductID fields from the field list to the query grid.


  3. Click the Totals button on the toolbar.


  4. In the Total row of the CategoryID column, select Group By. In the Total row of the ProductID column, select Count. Save the query as ProductCount.


  5. Create a new query based on the ProductCount query.


  6. Set the ProductCount field list's Alias property to Prod1.


  7. Drag both fields from the field list to the query grid, and then select Descending in the Sort row of the CountofProductID column.


  8. In the Field row of the third column, enter the following expression.


  9. 
       Ranking: (Select Count(*) from ProductCount Where [CountofProductID] > _
       [Prod1].[CountofProductID]) + 1 
  10. Run the query.


Example 3

This example demonstrates an alternative method of handling ties in ranking.

CAUTION: Following the steps in this example will modify the sample database Northwind.mdb. You may want to back up the Northwind.mdb file and perform these steps on a copy of the database.

  1. Repeat steps 1 through 8 in Example 2. After step 8, save the query as CatRanking. Run the query and note the tie in the number of products between the Seafood, Condiments, and Beverages categories.


  2. Create a new query based on the Products table. Drag the CategoryID and ProductID fields from the field list to the query grid.


  3. Click the Totals button on the toolbar.


  4. In the Total row of the CategoryID column, select Group By. In the Total row of the ProductID column, select Count.


  5. In the Show row of the CategoryID column, clear the check box.


  6. Set the UniqueValues property of the query to Yes.


  7. Run the query. Note that the query returns a list of the six different totals of orders placed. Save the query as DistinctCount.


  8. View the CatRanking query in Design view. Replace the expression in the Field row of the third column with the following expression, and then run the query.
    
       Ranking: (Select Count(*) from DistinctCount Where _ 
       [CountofProductID] > Prod1.[CountofProductID]) + 1 
    Note that the records following a tie in ranking are given the same rank number they would have received had there been no tie.


Additional query words: top first

Keywords : kbdta QryHowto
Version : WINDOWS:2000
Platform : WINDOWS
Issue type : kbinfo


Last Reviewed: November 10, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.