Skip to content

Commit c846849

Browse files
authored
Refresh RANK article and fix example query (UUF 508416) (#35893)
1 parent 6e2b013 commit c846849

File tree

2 files changed

+162
-144
lines changed

2 files changed

+162
-144
lines changed
Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,8 +1,8 @@
11
---
22
author: rwestMSFT
33
ms.author: randolphwest
4-
ms.date: 08/09/2023
4+
ms.date: 11/18/2025
55
ms.service: sql
66
ms.topic: include
77
---
8-
`AdventureWorksDW2022`
8+
`AdventureWorksDW2025`
Lines changed: 160 additions & 142 deletions
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,10 @@
11
---
22
title: "RANK (Transact-SQL)"
3-
description: "RANK (Transact-SQL)"
3+
description: RANK returns the rank of each row within the partition of a result set.
44
author: MikeRayMSFT
55
ms.author: mikeray
6-
ms.date: "10/25/2016"
6+
ms.reviewer: randolphwest
7+
ms.date: 11/20/2025
78
ms.service: sql
89
ms.subservice: t-sql
910
ms.topic: reference
@@ -22,152 +23,169 @@ dev_langs:
2223
monikerRange: ">=aps-pdw-2016 || =azuresqldb-current || =azure-sqldw-latest || >=sql-server-2016 || >=sql-server-linux-2017 || =azuresqldb-mi-current || =fabric || =fabric-sqldb"
2324
---
2425
# RANK (Transact-SQL)
26+
2527
[!INCLUDE [sql-asdb-asdbmi-asa-pdw-fabricse-fabricdw-fabricsqldb](../../includes/applies-to-version/sql-asdb-asdbmi-asa-pdw-fabricse-fabricdw-fabricsqldb.md)]
2628

27-
Returns the rank of each row within the partition of a result set. The rank of a row is one plus the number of ranks that come before the row in question.
28-
29-
ROW_NUMBER and RANK are similar. ROW_NUMBER numbers all rows sequentially (for example 1, 2, 3, 4, 5). RANK provides the same numeric value for ties (for example 1, 2, 2, 4, 5).
30-
31-
> [!NOTE]
32-
> RANK is a temporary value calculated when the query is run. To persist numbers in a table, see [IDENTITY Property](../../t-sql/statements/create-table-transact-sql-identity-property.md) and [SEQUENCE](../../t-sql/statements/create-sequence-transact-sql.md).
33-
34-
:::image type="icon" source="../../includes/media/topic-link-icon.svg" border="false"::: [Transact-SQL syntax conventions](../../t-sql/language-elements/transact-sql-syntax-conventions-transact-sql.md)
35-
36-
## Syntax
37-
38-
```sql
39-
RANK ( ) OVER ( [ partition_by_clause ] order_by_clause )
40-
```
41-
29+
Returns the rank of each row within the partition of a result set. The rank of a row is one plus the number of ranks that come before the row in question.
30+
31+
`ROW_NUMBER` and `RANK` are similar. `ROW_NUMBER` numbers all rows sequentially (for example 1, 2, 3, 4, 5). `RANK` provides the same numeric value for ties (for example 1, 2, 2, 4, 5).
32+
33+
> [!NOTE]
34+
> `RANK` is a temporary value calculated when the query is run. To persist numbers in a table, see [IDENTITY (Property)](../statements/create-table-transact-sql-identity-property.md) and [CREATE SEQUENCE](../statements/create-sequence-transact-sql.md).
35+
36+
:::image type="icon" source="../../includes/media/topic-link-icon.svg" border="false"::: [Transact-SQL syntax conventions](../../t-sql/language-elements/transact-sql-syntax-conventions-transact-sql.md)
37+
38+
## Syntax
39+
40+
```syntaxsql
41+
RANK ( ) OVER ( [ partition_by_clause ] order_by_clause )
42+
```
43+
4244
## Arguments
43-
OVER **(** [ _partition\_by\_clause_ ] _order\_by\_clause_**)**
44-
*partition_by_clause* divides the result set produced by the FROM clause into partitions to which the function is applied. If not specified, the function treats all rows of the query result set as a single group. _order\_by\_clause_ determines the order of the data before the function is applied. The *order_by_clause* is required. The \<rows or range clause/> of the OVER clause cannot be specified for the RANK function. For more information, see [OVER Clause &#40;Transact-SQL&#41;](../../t-sql/queries/select-over-clause-transact-sql.md).
45-
46-
## Return Types
47-
**bigint**
48-
49-
## Remarks
50-
If two or more rows tie for a rank, each tied row receives the same rank. For example, if the two top salespeople have the same SalesYTD value, they are both ranked one. The salesperson with the next highest SalesYTD is ranked number three, because there are two rows that are ranked higher. Therefore, the RANK function does not always return consecutive integers.
51-
52-
The sort order that is used for the whole query determines the order in which the rows appear in a result set.
53-
54-
RANK is nondeterministic. For more information, see [Deterministic and Nondeterministic Functions](../../relational-databases/user-defined-functions/deterministic-and-nondeterministic-functions.md).
55-
56-
## Examples
57-
58-
### A. Ranking rows within a partition
59-
The following example ranks the products in inventory the specified inventory locations according to their quantities. The result set is partitioned by `LocationID` and logically ordered by `Quantity`. Notice that in location 3, products 494 and 495 have the same quantity. Because they are tied, they are both ranked one.
60-
61-
```sql
62-
USE AdventureWorks2022;
63-
GO
64-
SELECT i.ProductID, p.Name, i.LocationID, i.Quantity
65-
,RANK() OVER
66-
(PARTITION BY i.LocationID ORDER BY i.Quantity DESC) AS Rank
67-
FROM Production.ProductInventory AS i
68-
INNER JOIN Production.Product AS p
69-
ON i.ProductID = p.ProductID
70-
WHERE i.LocationID BETWEEN 3 AND 4
71-
ORDER BY i.LocationID;
72-
GO
73-
```
74-
75-
[!INCLUDE[ssResult](../../includes/ssresult-md.md)]
76-
77-
```
78-
ProductID Name LocationID Quantity Rank
79-
----------- ---------------------- ------------ -------- ----
80-
494 Paint - Silver 3 49 1
81-
495 Paint - Blue 3 49 1
82-
493 Paint - Red 3 41 3
83-
496 Paint - Yellow 3 30 4
84-
492 Paint - Black 3 17 5
85-
495 Paint - Blue 4 35 1
86-
496 Paint - Yellow 4 25 2
87-
493 Paint - Red 4 24 3
88-
492 Paint - Black 4 14 4
89-
494 Paint - Silver 4 12 5
90-
(10 row(s) affected)
91-
```
92-
93-
### B. Ranking all rows in a result set
94-
The following example returns the top ten employees ranked by their salary. Because a PARTITION BY clause was not specified, the RANK function was applied to all rows in the result set.
95-
96-
```sql
97-
USE AdventureWorks2022
98-
SELECT TOP(10) BusinessEntityID, Rate,
99-
RANK() OVER (ORDER BY Rate DESC) AS RankBySalary
100-
FROM HumanResources.EmployeePayHistory AS eph1
101-
WHERE RateChangeDate = (SELECT MAX(RateChangeDate)
102-
FROM HumanResources.EmployeePayHistory AS eph2
103-
WHERE eph1.BusinessEntityID = eph2.BusinessEntityID)
104-
ORDER BY BusinessEntityID;
105-
```
106-
107-
[!INCLUDE[ssResult](../../includes/ssresult-md.md)]
108-
45+
46+
#### OVER ( [ *partition_by_clause* ] *order_by_clause* )
47+
48+
The *partition_by_clause* divides the result set produced by the `FROM` clause into partitions to which the function is applied. If not specified, the function treats all rows of the query result set as a single group.
49+
50+
The *order_by_clause* determines the order of the data before the function is applied. The *order_by_clause* is required. The `<rows or range clause>` of the `OVER` clause can't be specified for the `RANK` function. For more information, see [SELECT - OVER clause](../queries/select-over-clause-transact-sql.md).
51+
52+
## Return types
53+
54+
**bigint**
55+
56+
## Remarks
57+
58+
If two or more rows tie for a rank, each tied row receives the same rank. For example, if the two top salespeople have the same `SalesYTD` value, they're both ranked one. The salesperson with the next highest `SalesYTD` is ranked number three, because there are two rows that are ranked higher. Therefore, the `RANK` function doesn't always return consecutive integers.
59+
60+
The sort order that is used for the whole query determines the order in which the rows appear in a result set.
61+
62+
`RANK` is nondeterministic. For more information, see [Deterministic and nondeterministic functions](../../relational-databases/user-defined-functions/deterministic-and-nondeterministic-functions.md).
63+
64+
## Examples
65+
66+
[!INCLUDE [article-uses-adventureworks](../../includes/article-uses-adventureworks.md)]
67+
68+
### A. Rank rows within a partition
69+
70+
The following example ranks the products in inventory the specified inventory locations according to their quantities. The result set is partitioned by `LocationID` and logically ordered by `Quantity`. In location 3, products 494 and 495 have the same quantity. Because they're tied, they're both ranked one.
71+
72+
```sql
73+
USE AdventureWorks2025;
74+
GO
75+
76+
SELECT i.ProductID,
77+
p.Name,
78+
i.LocationID,
79+
i.Quantity,
80+
RANK() OVER (PARTITION BY i.LocationID ORDER BY i.Quantity DESC) AS Rank
81+
FROM Production.ProductInventory AS i
82+
INNER JOIN Production.Product AS p
83+
ON i.ProductID = p.ProductID
84+
WHERE i.LocationID BETWEEN 3 AND 4
85+
ORDER BY i.LocationID;
86+
```
87+
88+
[!INCLUDE [ssResult](../../includes/ssresult-md.md)]
89+
90+
```output
91+
ProductID Name LocationID Quantity Rank
92+
----------- ---------------------- ------------ -------- ----
93+
494 Paint - Silver 3 49 1
94+
495 Paint - Blue 3 49 1
95+
493 Paint - Red 3 41 3
96+
496 Paint - Yellow 3 30 4
97+
492 Paint - Black 3 17 5
98+
495 Paint - Blue 4 35 1
99+
496 Paint - Yellow 4 25 2
100+
493 Paint - Red 4 24 3
101+
492 Paint - Black 4 14 4
102+
494 Paint - Silver 4 12 5
109103
```
110-
BusinessEntityID Rate RankBySalary
111-
---------------- --------------------- --------------------
112-
1 125.50 1
113-
2 63.4615 4
114-
3 43.2692 11
115-
4 29.8462 28
116-
5 32.6923 22
117-
6 32.6923 22
118-
7 50.4808 6
119-
8 40.8654 14
120-
9 40.8654 14
121-
10 42.4808 13
122-
```
123-
124-
## Examples: [!INCLUDE[ssazuresynapse-md](../../includes/ssazuresynapse-md.md)] and [!INCLUDE[ssPDW](../../includes/sspdw-md.md)]
125-
126-
### C: Ranking rows within a partition
127-
The following example ranks the sales representatives in each sales territory according to their total sales. The rowset is partitioned by `SalesTerritoryGroup` and sorted by `SalesAmountQuota`.
128-
129-
```sql
130-
-- Uses AdventureWorks
131-
132-
SELECT LastName, SUM(SalesAmountQuota) AS TotalSales, SalesTerritoryRegion,
133-
RANK() OVER (PARTITION BY SalesTerritoryRegion ORDER BY SUM(SalesAmountQuota) DESC ) AS RankResult
134-
FROM dbo.DimEmployee AS e
135-
INNER JOIN dbo.FactSalesQuota AS sq ON e.EmployeeKey = sq.EmployeeKey
136-
INNER JOIN dbo.DimSalesTerritory AS st ON e.SalesTerritoryKey = st.SalesTerritoryKey
137-
WHERE SalesPersonFlag = 1 AND SalesTerritoryRegion != N'NA'
138-
GROUP BY LastName, SalesTerritoryRegion;
139-
```
140-
141-
[!INCLUDE[ssResult](../../includes/ssresult-md.md)]
142-
104+
105+
### B. Rank all rows in a result set
106+
107+
The following example returns the top 10 employees ranked by their salary. Because a `PARTITION BY` clause isn't specified, the `RANK` function is applied to all rows in the result set.
108+
109+
```sql
110+
USE AdventureWorks2025;
111+
GO
112+
113+
SELECT TOP (10) BusinessEntityID,
114+
Rate,
115+
RANK() OVER (ORDER BY Rate DESC) AS RankBySalary
116+
FROM HumanResources.EmployeePayHistory AS eph1
117+
WHERE RateChangeDate = (
118+
SELECT MAX(RateChangeDate)
119+
FROM HumanResources.EmployeePayHistory AS eph2
120+
WHERE eph1.BusinessEntityID = eph2.BusinessEntityID
121+
)
122+
ORDER BY BusinessEntityID;
143123
```
144-
LastName TotalSales SalesTerritoryRegion RankResult
145-
---------------- ------------- ------------------- --------
146-
Tsoflias 1687000.0000 Australia 1
147-
Saraiva 7098000.0000 Canada 1
148-
Vargas 4365000.0000 Canada 2
149-
Carson 12198000.0000 Central 1
150-
Varkey Chudukatil 5557000.0000 France 1
151-
Valdez 2287000.0000 Germany 1
152-
Blythe 11162000.0000 Northeast 1
153-
Campbell 4025000.0000 Northwest 1
154-
Ansman-Wolfe 3551000.0000 Northwest 2
155-
Mensa-Annan 2753000.0000 Northwest 3
156-
Reiter 8541000.0000 Southeast 1
157-
Mitchell 11786000.0000 Southwest 1
158-
Ito 7804000.0000 Southwest 2
159-
Pak 10514000.0000 United Kingdom 1
160-
```
161-
162-
## See Also
163-
[DENSE_RANK &#40;Transact-SQL&#41;](../../t-sql/functions/dense-rank-transact-sql.md)
164-
[ROW_NUMBER &#40;Transact-SQL&#41;](../../t-sql/functions/row-number-transact-sql.md)
165-
[NTILE &#40;Transact-SQL&#41;](../../t-sql/functions/ntile-transact-sql.md)
166-
[Ranking Functions &#40;Transact-SQL&#41;](../../t-sql/functions/ranking-functions-transact-sql.md)
167-
[Built-in Functions &#40;Transact-SQL&#41;](~/t-sql/functions/functions.md)
168-
169-
170124

125+
[!INCLUDE [ssResult](../../includes/ssresult-md.md)]
171126

127+
```output
128+
BusinessEntityID Rate RankBySalary
129+
---------------- --------------------- --------------------
130+
1 125.50 1
131+
2 63.4615 4
132+
3 43.2692 11
133+
4 29.8462 28
134+
5 32.6923 22
135+
6 32.6923 22
136+
7 50.4808 6
137+
8 40.8654 14
138+
9 40.8654 14
139+
10 42.4808 13
140+
```
141+
142+
## Examples: Azure Synapse Analytics and Analytics Platform System (PDW)
143+
144+
### C: Ranking rows within a partition
145+
146+
The following example ranks the sales representatives in each sales territory according to their total sales. The rowset is partitioned by `SalesTerritoryGroup` and sorted by `SalesAmountQuota`.
147+
148+
```sql
149+
-- Uses AdventureWorks
150+
SELECT e.LastName,
151+
st.SalesTerritoryGroup,
152+
SUM(sq.SalesAmountQuota) AS TotalSales,
153+
RANK() OVER (PARTITION BY st.SalesTerritoryGroup ORDER BY SUM(sq.SalesAmountQuota) DESC) AS RankResult
154+
FROM dbo.DimEmployee AS e
155+
INNER JOIN dbo.FactSalesQuota AS sq
156+
ON e.EmployeeKey = sq.EmployeeKey
157+
INNER JOIN dbo.DimSalesTerritory AS st
158+
ON e.SalesTerritoryKey = st.SalesTerritoryKey
159+
WHERE e.SalesPersonFlag = 1
160+
AND st.SalesTerritoryGroup <> N'NA'
161+
GROUP BY e.LastName, st.SalesTerritoryGroup;
162+
```
163+
164+
[!INCLUDE [ssResult](../../includes/ssresult-md.md)]
165+
166+
```output
167+
LastName SalesTerritoryGroup TotalSales RankResult
168+
------------------ -------------------- ------------ -----------
169+
Pak Europe 10514000.00 1
170+
Varkey Chudukatil Europe 5557000.00 2
171+
Valdez Europe 2287000.00 3
172+
Carson North America 12198000.00 1
173+
Mitchell North America 11786000.00 2
174+
Blythe North America 11162000.00 3
175+
Reiter North America 8541000.00 4
176+
Ito North America 7804000.00 5
177+
Saraiva North America 7098000.00 6
178+
Vargas North America 4365000.00 7
179+
Campbell North America 4025000.00 8
180+
Ansman-Wolfe North America 3551000.00 9
181+
Mensa-Annan North America 2753000.00 10
182+
Tsoflias Pacific 1687000.00 1
183+
```
172184

185+
## Related content
173186

187+
- [DENSE_RANK (Transact-SQL)](dense-rank-transact-sql.md)
188+
- [ROW_NUMBER (Transact-SQL)](row-number-transact-sql.md)
189+
- [NTILE (Transact-SQL)](ntile-transact-sql.md)
190+
- [Ranking Functions (Transact-SQL)](ranking-functions-transact-sql.md)
191+
- [What are the SQL database functions?](functions.md)

0 commit comments

Comments
 (0)