Skip to main content

WINDOW_FUNCTION_PERCENT_RANK

WINDOW FUNCTION PERCENT_RANK​

description​

The PERCENT_RANK() is a window function that calculates the percentile rank of a row within a partition or result set.

The following shows the syntax of the PERCENT_RANK() function:

PERCENT_RANK() OVER (
PARTITION BY partition_expression
ORDER BY
sort_expression [ASC | DESC]
)

The PERCENT_RANK() function returns a number that ranges from zero to one.

For a specified row, PERCENT_RANK() calculates the rank of that row minus one, divided by 1 less than the number of rows in the evaluated partition or query result set:

(rank - 1) / (total_rows - 1)

In this formula, rank is the rank of a specified row and total_rows is the number of rows being evaluated.

The PERCENT_RANK() function always returns zero for the first row in a partition or result set. The repeated column values will receive the same PERCENT_RANK() value.

Similar to other window functions, the PARTITION BY clause distributes the rows into partitions and the ORDER BY clause specifies the logical order of rows in each partition. The PERCENT_RANK() function is calculated for each ordered partition independently.

Both PARTITION BY and ORDER BY clauses are optional. However, the PERCENT_RANK() is an order-sensitive function, therefore, you should always use the ORDER BY clause.

example​

// create table
CREATE TABLE test_percent_rank (
productLine VARCHAR,
orderYear INT,
orderValue DOUBLE,
percentile_rank DOUBLE
) ENGINE=OLAP
DISTRIBUTED BY HASH(`orderYear`) BUCKETS 4
PROPERTIES (
"replication_allocation" = "tag.location.default: 1"
);

// insert data into table
INSERT INTO test_percent_rank (productLine, orderYear, orderValue, percentile_rank) VALUES
('Motorcycles', 2003, 2440.50, 0.00),
('Trains', 2003, 2770.95, 0.17),
('Trucks and Buses', 2003, 3284.28, 0.33),
('Vintage Cars', 2003, 4080.00, 0.50),
('Planes', 2003, 4825.44, 0.67),
('Ships', 2003, 5072.71, 0.83),
('Classic Cars', 2003, 5571.80, 1.00),
('Motorcycles', 2004, 2598.77, 0.00),
('Vintage Cars', 2004, 2819.28, 0.17),
('Planes', 2004, 2857.35, 0.33),
('Ships', 2004, 4301.15, 0.50),
('Trucks and Buses', 2004, 4615.64, 0.67),
('Trains', 2004, 4646.88, 0.83),
('Classic Cars', 2004, 8124.98, 1.00),
('Ships', 2005, 1603.20, 0.00),
('Motorcycles', 2005, 3774.00, 0.17),
('Planes', 2005, 4018.00, 0.50),
('Vintage Cars', 2005, 5346.50, 0.67),
('Classic Cars', 2005, 5971.35, 0.83),
('Trucks and Buses', 2005, 6295.03, 1.00);

// query
SELECT
productLine,
orderYear,
orderValue,
ROUND(
PERCENT_RANK()
OVER (
PARTITION BY orderYear
ORDER BY orderValue
),2) percentile_rank
FROM
test_percent_rank
ORDER BY
orderYear;

// result
+------------------+-----------+------------+-----------------+
| productLine | orderYear | orderValue | percentile_rank |
+------------------+-----------+------------+-----------------+
| Motorcycles | 2003 | 2440.5 | 0 |
| Trains | 2003 | 2770.95 | 0.17 |
| Trucks and Buses | 2003 | 3284.28 | 0.33 |
| Vintage Cars | 2003 | 4080 | 0.5 |
| Planes | 2003 | 4825.44 | 0.67 |
| Ships | 2003 | 5072.71 | 0.83 |
| Classic Cars | 2003 | 5571.8 | 1 |
| Motorcycles | 2004 | 2598.77 | 0 |
| Vintage Cars | 2004 | 2819.28 | 0.17 |
| Planes | 2004 | 2857.35 | 0.33 |
| Ships | 2004 | 4301.15 | 0.5 |
| Trucks and Buses | 2004 | 4615.64 | 0.67 |
| Trains | 2004 | 4646.88 | 0.83 |
| Classic Cars | 2004 | 8124.98 | 1 |
| Ships | 2005 | 1603.2 | 0 |
| Motorcycles | 2005 | 3774 | 0.2 |
| Planes | 2005 | 4018 | 0.4 |
| Vintage Cars | 2005 | 5346.5 | 0.6 |
| Classic Cars | 2005 | 5971.35 | 0.8 |
| Trucks and Buses | 2005 | 6295.03 | 1 |
+------------------+-----------+------------+-----------------+

keywords​

WINDOW,FUNCTION,PERCENT_RANK