The information in this article applies to:
- Microsoft Access versions 2.0, 7.0, 97
SUMMARY
Advanced: Requires expert coding, interoperability, and multiuser skills.
This article contains three examples that demonstrate 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 containing 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 (or NWIND.MDB in version 2.0 or earlier). You may
want to back up the Northwind.mdb (or NWIND.MDB) file and perform these
steps on a copy of the database.
- Open the sample Northwind.mdb (or NWIND.MDB in version 2.0) and create
a new query based on the Employees table.
- If the property sheet is not displayed, click the Properties button on
the toolbar.
- Click the title bar of the Employees field list, and then set the
field list's Alias property to Emp1.
- Drag the LastName and HireDate fields from the field list to the
query grid.
NOTE: In version 2.0, there is a space in the Last Name and the Hire
Date fields.
- In the HireDate column's Sort row, select Ascending.
- In the third column's Field row, enter the following expression.
NOTE: In the following expressions, an underscore (_) at the end of a
line is used as a line-continuation character. Remove the underscore
from the end of the line when re-creating these expressions.
Seniority: (Select Count(*) from Employees Where _
[HireDate] < [Emp1].[HireDate];)
- 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:
Seniority: (Select Count(*) from Employees Where _
[HireDate] < [Emp1].[HireDate]+1;)
- 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 (or NWIND.MDB in version 2.0 or earlier). You may
want to back up the Northwind.mdb (or NWIND.MDB) file and perform these
steps on a copy of the database.
- Create a new query based on the Products table.
- Drag the CategoryID and ProductID fields from the field list to the
query grid.
NOTE: In version 2.0, there is a space in the Category ID and the
Product ID fields.
- Click the Totals button on the toolbar.
- In the CategoryID column's Total row, select Group By. In the ProductID
column's Total row, select Count. Save the query as ProductCount.
- Create a new query based on the ProductCount query.
- Set the ProductCount field list's Alias property to Prod1.
- Drag both fields from the field list to the query grid, and then
select Descending in the CountofProductID column's Sort row.
- In the third column's Field row, enter the following expression.
NOTE: In the following expression, an underscore (_) at the end of a
line is used as a line-continuation character. Remove the underscore
from the end of the line when re-creating this expression.
Ranking: (Select Count(*) from ProductCount Where _
[CountofProductID] > [Prod1].[CountofProductID]) + 1
- 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 (or NWIND.MDB in version 2.0 or earlier). You may
want to back up the Northwind.mdb (or NWIND.MDB) file and perform these
steps on a copy of the database.
- Repeat steps 1-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, CategoryIDs
8, 2, and 1, respectively.
NOTE: In version 2.0, there is a space in the Category ID field.
- Create a new query based on the Products table. Drag the CategoryID
and ProductID fields from the field list to the query grid.
NOTE: In version 2.0, there is a space in the Product ID field.
- Click the Totals button on the toolbar.
- In the CategoryID column's Total row, select Group By. In the ProductID
column's Total row, select Count.
- In the CategoryID column's Show row, clear the check box.
- Set the query's UniqueValues property to Yes.
- Run the query. Note that the query returns a list of the eight
different totals of orders placed. Save the query as DistinctCount.
- View the CatRanking query in Design view. Replace the expression
in the third column's Field row with the following expression, and
then run the query.
NOTE: In the following expression, an underscore (_) at the end of a
line is used as a line-continuation character. Remove the underscore
from the end of the line when re-creating this expression.
Ranking: (Select Count(*) from DistinctCount Where _
[CountofProductID] > Prod1.[CountofProductID]) + 1