RANK
Returns the rank of each row within the partition of a result set.
The rank of a row is defined as 1 + the number of ranks that come before the row
.
While ROW_NUMBER numbers all rows sequentially, RANK
provides the same value for identical consecutive rows (e.g. 1, 2, 2, 4, 4, 6).
Syntax
RANK( )
OVER (
[ PARTITION BY partition_expr [, ...] ]
[ ORDER BY order [ ASC | DESC ] [, ...]]
)
Arguments
None
Returns
The rank of the row, with data type BIGINT
.
Notes
The
ORDER BY
clause that is used determines the order in which the rows appear in a result set, and thus the rank.Rank is non-deterministic. It may return different results each time it is called with a specific set of input values even if there has been no change in the table contents.
Examples
For these examples, assume a table named nba
, with the following structure:
CREATE TABLE nba
(
"Name" text(40),
"Team" text(40),
"Number" tinyint,
"Position" text(2),
"Age" tinyint,
"Height" text(4),
"Weight" real,
"College" text(40),
"Salary" float
);
Here’s a peek at the table contents (Download nba.csv
):
Name |
Team |
Number |
Position |
Age |
Height |
Weight |
College |
Salary |
---|---|---|---|---|---|---|---|---|
Avery Bradley |
Boston Celtics |
0.0 |
PG |
25.0 |
6-2 |
180.0 |
Texas |
7730337.0 |
Jae Crowder |
Boston Celtics |
99.0 |
SF |
25.0 |
6-6 |
235.0 |
Marquette |
6796117.0 |
John Holland |
Boston Celtics |
30.0 |
SG |
27.0 |
6-5 |
205.0 |
Boston University |
|
R.J. Hunter |
Boston Celtics |
28.0 |
SG |
22.0 |
6-5 |
185.0 |
Georgia State |
1148640.0 |
Jonas Jerebko |
Boston Celtics |
8.0 |
PF |
29.0 |
6-10 |
231.0 |
5000000.0 |
|
Amir Johnson |
Boston Celtics |
90.0 |
PF |
29.0 |
6-9 |
240.0 |
12000000.0 |
|
Jordan Mickey |
Boston Celtics |
55.0 |
PF |
21.0 |
6-8 |
235.0 |
LSU |
1170960.0 |
Kelly Olynyk |
Boston Celtics |
41.0 |
C |
25.0 |
7-0 |
238.0 |
Gonzaga |
2165160.0 |
Terry Rozier |
Boston Celtics |
12.0 |
PG |
22.0 |
6-2 |
190.0 |
Louisville |
1824360.0 |
RANK
vs. ROW_NUMBER
t=> SELECT ROW_NUMBER () OVER (PARTITION BY "Age" ORDER BY "Height") FROM nba;
row_number
----------
1
2
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
1
2
3
4
[...]
t=> SELECT RANK () OVER (PARTITION BY "Age" ORDER BY "Height") FROM nba;
rank
----
1
1
1
2
2
2
5
6
6
8
8
10
10
10
13
14
14
14
14
18
19
1
2
2
2
[...]