Window Functions
Window Functions
Window functions and the OVER clause are used together. The OVER clause is used for grouping data and sorting the elements in a group. Window functions are used for generating sequence numbers for the values in the group.

order by in a window function must be followed by a column name. If it is followed by a number, the number is processed as a constant value and the target column is not ranked.
- RANK()
Description: Generates non-consecutive sequence numbers for the values in each group. The same values have the same sequence number.
Return type: bigint
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17
openGauss=# CREATE TABLE rank_t1(a int, b int); openGauss=# INSERT INTO rank_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6); openGauss=# SELECT a,b,RANK() OVER(PARTITION BY a ORDER BY b) FROM rank_t1; a | b | rank ---+---+------ 1 | 1 | 1 1 | 1 | 1 1 | 2 | 3 1 | 3 | 4 2 | 4 | 1 2 | 5 | 2 3 | 6 | 1 (7 rows) openGauss=# DROP TABLE rank_t1;
- ROW_NUMBER()
Description: Generates consecutive sequence numbers for the values in each group. The same values have different sequence numbers.
Return type: bigint
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17
openGauss=# CREATE TABLE row_number_t1(a int, b int); openGauss=# INSERT INTO row_number_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6); openGauss=# SELECT a,b,ROW_NUMBER() OVER(PARTITION BY a ORDER BY b) FROM row_number_t1; a | b | row_number ---+---+------------ 1 | 1 | 1 1 | 1 | 2 1 | 2 | 3 1 | 3 | 4 2 | 4 | 1 2 | 5 | 2 3 | 6 | 1 (7 rows) openGauss=# DROP TABLE row_number_t1;
- DENSE_RANK()
Description: Generates consecutive sequence numbers for the values in each group. The same values have the same sequence number.
Return type: bigint
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17
openGauss=# CREATE TABLE dense_rank_t1(a int, b int); openGauss=# INSERT INTO dense_rank_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6); openGauss=# SELECT a,b,DENSE_RANK() OVER(PARTITION BY a ORDER BY b) FROM dense_rank_t1; a | b | dense_rank ---+---+------------ 1 | 1 | 1 1 | 1 | 1 1 | 2 | 2 1 | 3 | 3 2 | 4 | 1 2 | 5 | 2 3 | 6 | 1 (7 rows) openGauss=# DROP TABLE dense_rank_t1;
- PERCENT_RANK()
Description: The PERCENT_RANK function is used for generating corresponding sequence numbers for the values in each group. That is, the function calculates the value according to the formula: Sequence number = (rank – 1) / (totalrows – 1). rank is the corresponding sequence number generated based on the RANK function for the value and totalrows is the total number of elements in a group.
Return type: double precision
Example:
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17
openGauss=# CREATE TABLE percent_rank_t1(a int, b int); openGauss=# INSERT INTO percent_rank_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6); openGauss=# SELECT a,b,PERCENT_RANK() OVER(PARTITION BY a ORDER BY b) FROM percent_rank_t1; a | b | percent_rank ---+---+------------------ 1 | 1 | 0 1 | 1 | 0 1 | 2 | .666666666666667 1 | 3 | 1 2 | 4 | 0 2 | 5 | 1 3 | 6 | 0 (7 rows) openGauss=# DROP TABLE percent_rank_t1;
- CUME_DIST()
Description: Generates accumulative distribution sequence numbers for the values in each group. That is, the function calculates the value according to the following formula: Sequence number = Number of rows preceding or peer with current row/Total rows.
Return type: double precision
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17
openGauss=# CREATE TABLE cume_dist_t1(a int, b int); openGauss=# INSERT INTO cume_dist_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6); openGauss=# SELECT a,b,CUME_DIST() OVER(PARTITION BY a ORDER BY b) FROM cume_dist_t1; a | b | cume_dist ---+---+----------- 1 | 1 | .5 1 | 1 | .5 1 | 2 | .75 1 | 3 | 1 2 | 4 | .5 2 | 5 | 1 3 | 6 | 1 (7 rows) openGauss=# DROP TABLE cume_dist_t1;
- NTILE(num_buckets integer)
Description: Equally allocates sequential data sets to the buckets whose quantity is specified by num_buckets according to num_buckets integer and allocates the bucket number to each row. Divide the partition as evenly as possible.
Return type: integer
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17
openGauss=# CREATE TABLE ntile_t1(a int, b int); openGauss=# INSERT INTO ntile_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6); openGauss=# SELECT a,b,NTILE(2) OVER(PARTITION BY a ORDER BY b) FROM ntile_t1; a | b | ntile ---+---+------- 1 | 1 | 1 1 | 1 | 1 1 | 2 | 2 1 | 3 | 2 2 | 4 | 1 2 | 5 | 2 3 | 6 | 1 (7 rows) openGauss=# DROP TABLE ntile_t1;
- LAG(value any [, offset integer [, default any ]])
Description: Generates lag values for the corresponding values in each group. That is, the value of the row obtained by moving forward the row corresponding to the current value by offset (integer) is the sequence number. If the row does not exist after the moving, the result value is the default value. If omitted, offset defaults to 1 and default to NULL. The type of the default value must be the same as that of the value value.
Return type: same as the parameter type
Example:
-- Create a table and insert data into the table. openGauss=# CREATE TABLE ta1 (hire_date date, last_name varchar(20), department_id int); CREATE TABLE openGauss=# INSERT INTO ta1 values('07-DEC-02', 'Raphaely', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('24-JUL-05', 'Tobias', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('24-DEC-05', 'Baida', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('18-MAY-03', 'Khoo', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('15-NOV-06', 'Himuro', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('10-AUG-07', 'Colmenares', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('10-MAY-07', 'yq', 11); INSERT 0 1 openGauss=# INSERT INTO ta1 values('10-MAY-08', 'zi', 11); INSERT 0 1 openGauss=# INSERT INTO ta1 values('', 'yq1', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values(null, 'yq2', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('10-DEC-07', 'yq3', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values(null, null, 11); INSERT 0 1 openGauss=# INSERT INTO ta1 values(null, null, 11); INSERT 0 1 -- Call LAG and set offset to 3 and default to null. openGauss=# SELECT hire_date, last_name, department_id, lag(hire_date, 3, null) OVER (PARTITION BY department_id ORDER BY last_name) AS "NextHired" FROM ta1 ORDER BY department_id; hire_date | last_name | department_id | NextHired ---------------------+------------+---------------+--------------------- 2007-05-10 00:00:00 | yq | 11 | 2008-05-10 00:00:00 | zi | 11 | | | 11 | | | 11 | 2007-05-10 00:00:00 2005-12-24 00:00:00 | Baida | 30 | 2007-08-10 00:00:00 | Colmenares | 30 | 2006-11-15 00:00:00 | Himuro | 30 | 2003-05-18 00:00:00 | Khoo | 30 | 2005-12-24 00:00:00 2002-12-07 00:00:00 | Raphaely | 30 | 2007-08-10 00:00:00 2005-07-24 00:00:00 | Tobias | 30 | 2006-11-15 00:00:00 | yq1 | 30 | 2003-05-18 00:00:00 | yq2 | 30 | 2002-12-07 00:00:00 2007-12-10 00:00:00 | yq3 | 30 | 2005-07-24 00:00:00 (13 rows) openGauss=# DROP TABLE ta1;
- LEAD(value any [, offset integer [, default any ]])
Description: Generates leading values for the corresponding values in each group. That is, the value of the row obtained by moving backward the row corresponding to the current value by offset (integer) is the sequence number. If the row after the moving exceeds the total number of rows for the current group, the result value is the default value. If omitted, offset defaults to 1 and default to NULL. The type of the default value must be the same as that of the value value.
Return type: same as the parameter type
Example:
openGauss=# CREATE TABLE ta1 (hire_date date, last_name varchar(20), department_id int); CREATE TABLE openGauss=# INSERT INTO ta1 values('07-DEC-02', 'Raphaely', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('24-JUL-05', 'Tobias', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('24-DEC-05', 'Baida', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('18-MAY-03', 'Khoo', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('15-NOV-06', 'Himuro', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('10-AUG-07', 'Colmenares', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('10-MAY-07', 'yq', 11); INSERT 0 1 openGauss=# INSERT INTO ta1 values('10-MAY-08', 'zi', 11); INSERT 0 1 openGauss=# INSERT INTO ta1 values('', 'yq1', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values(null, 'yq2', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values('10-DEC-07', 'yq3', 30); INSERT 0 1 openGauss=# INSERT INTO ta1 values(null, null, 11); INSERT 0 1 openGauss=# INSERT INTO ta1 values(null, null, 11); INSERT 0 1 -- Call LEAD and set offset to 2. openGauss=# SELECT hire_date, last_name, department_id, lead(hire_date, 2) OVER (PARTITION BY department_id ORDER BY last_name) AS "NextHired" FROM ta1 ORDER BY department_id; hire_date | last_name | department_id | NextHired ---------------------+------------+---------------+--------------------- 2007-05-10 00:00:00 | yq | 11 | 2008-05-10 00:00:00 | zi | 11 | | | 11 | | | 11 | 2005-12-24 00:00:00 | Baida | 30 | 2006-11-15 00:00:00 2007-08-10 00:00:00 | Colmenares | 30 | 2003-05-18 00:00:00 2006-11-15 00:00:00 | Himuro | 30 | 2002-12-07 00:00:00 2003-05-18 00:00:00 | Khoo | 30 | 2005-07-24 00:00:00 2002-12-07 00:00:00 | Raphaely | 30 | 2005-07-24 00:00:00 | Tobias | 30 | | yq1 | 30 | 2007-12-10 00:00:00 | yq2 | 30 | 2007-12-10 00:00:00 | yq3 | 30 | (13 rows) openGauss=# DROP TABLE ta1;
- FIRST_VALUE(value any)
Description: Returns the first value of each group.
Return type: same as the parameter type
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17
openGauss=# CREATE TABLE first_value_t1(a int, b int); openGauss=# INSERT INTO first_value_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6); openGauss=# SELECT a,b,FIRST_VALUE(b) OVER(PARTITION BY a ORDER BY b) FROM first_value_t1; a | b | first_value ---+---+------------- 1 | 1 | 1 1 | 1 | 1 1 | 2 | 1 1 | 3 | 1 2 | 4 | 4 2 | 5 | 4 3 | 6 | 6 (7 rows) openGauss=# DROP TABLE first_value_t1;
- LAST_VALUE(value any)
Description: Returns the last value of each group.
Return type: same as the parameter type
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17
openGauss=# CREATE TABLE last_value_t1(a int, b int); openGauss=# INSERT INTO last_value_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6); openGauss=# SELECT a,b,LAST_VALUE(b) OVER(PARTITION BY a ORDER BY b) FROM last_value_t1; a | b | last_value ---+---+------------ 1 | 1 | 1 1 | 1 | 1 1 | 2 | 2 1 | 3 | 3 2 | 4 | 4 2 | 5 | 5 3 | 6 | 6 (7 rows) openGauss=# DROP TABLE last_value_t1;
- NTH_VALUE(value any, nth integer)
Description: Returns the nth row for a group. If the row does not exist, NULL is returned by default.
Return type: same as the parameter type
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17
openGauss=# CREATE TABLE nth_value_t1(a int, b int); openGauss=# INSERT INTO nth_value_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6); openGauss=# SELECT a,b,NTH_VALUE(b, 2) OVER(PARTITION BY a order by b) FROM nth_value_t1; a | b | nth_value ---+---+----------- 1 | 1 | 1 1 | 1 | 1 1 | 2 | 1 1 | 3 | 1 2 | 4 | 2 | 5 | 5 3 | 6 | (7 rows) openGauss=# DROP TABLE nth_value_t1;
- delta
Description: Returns the difference between the current row and the previous row.
Parameter: numeric
Return type: numeric
- spread
Description: Calculates the difference between the maximum value and minimum value in a certain period.
Parameter: real
Return type: real
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot