Updated on 2024-08-20 GMT+08:00

Window Functions

Window Functions

This statement is used together with the window function. 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.

If a parent query contains filter criteria of a window function in a subquery, the filter criteria in the parent query can be pushed down to the subquery.

  1. Only the <, <=, and = filter criteria of window functions in parent queries can be pushed down to subqueries.
  2. The upper boundary of a restriction condition range can be a constant, constant expression, parameter, non-VOLATILE function, or non-correlated sublink.
  3. Only the ROW_NUMB, ROW_NUMBER(), RANK(), and DENSE_RANK() window functions are supported.

Example:

-- Create a table.
gaussdb=# CREATE TABLE t2 (c1 INT, c2 INT);
-- Import data.
gaussdb=# INSERT INTO t2 SELECT generate_series, generate_series FROM generate_series(1, 1000000);
-- Execute the query. The query is normal, no error is reported, and the execution result is correct.
gaussdb=# EXPLAIN ANALYZE SELECT nc1 FROM (
SELECT row_number() over() rid,
t2.c1 nc1
FROM t2
) WHERE rid BETWEEN 1 AND (1 + 10 - 1);
                                                     QUERY PLAN                                                     
--------------------------------------------------------------------------------------------------------------------
Streaming (type: GATHER)  (cost=0.12..10.64 rows=5 width=4) (actual time=10.201..12.766 rows=10 loops=1)
   Node/s: All datanodes
   ->  Subquery Scan on __unnamed_subquery__  (cost=0.00..10.45 rows=5 width=4) (actual time=[5.310,6.092]..[5.310,6.092], rows=10)
         Filter: (__unnamed_subquery__.rid >= 1)
         ->  WindowAgg  (cost=0.00..10.25 rows=16 width=4) (actual time=[5.262,5.873]..[5.262,5.873], rows=10)
               row_number_filter: (row_number() OVER () <= 10)
               ->  Streaming(type: BROADCAST)  (cost=0.00..10.29 rows=32 width=4) (actual time=[5.162,5.682]..[5.162,5.682], rows=11)
                     Spawn on: All datanodes
                     ->  WindowAgg  (cost=0.00..10.25 rows=16 width=4) (actual time=[1.759,1.815]..[1.786,1.844], rows=20)
                           row_number_filter: (row_number() OVER () <= 10)
                           ->  Seq Scan on t2  (cost=0.00..13.13 rows=20 width=4) (actual time=[1.711,1.716]..[1.743,1.747], rows=22)
 Total runtime: 13.428 ms
(12 rows)
-- Clear the environment to prevent data leakage.
gaussdb=# DROP TABLE t2;
  • RANK()

    Description: The RANK function is used for generating 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
    gaussdb=# CREATE TABLE rank_t1(a int, b int);
    
    gaussdb=# INSERT INTO rank_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# 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)
    
    gaussdb=# DROP TABLE rank_t1;
    
  • ROW_NUMBER()

    Description: The ROW_NUMBER function is used for generating 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
    gaussdb=# CREATE TABLE row_number_t1(a int, b int);
    
    gaussdb=# INSERT INTO row_number_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# 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)
    
    gaussdb=# DROP TABLE row_number_t1;
    
  • DENSE_RANK()

    Description: The DENSE_RANK function is used for generating 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
    gaussdb=# CREATE TABLE dense_rank_t1(a int, b int);
    
    gaussdb=# INSERT INTO dense_rank_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# 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)
    
    gaussdb=# 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:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    gaussdb=# CREATE TABLE percent_rank_t1(a int, b int);
    
    gaussdb=# INSERT INTO percent_rank_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# 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)
    
    gaussdb=# DROP TABLE percent_rank_t1;
    
  • CUME_DIST()

    Description: The CUME_DIST function is used for generating 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
    gaussdb=# CREATE TABLE cume_dist_t1(a int, b int);
    
    gaussdb=# INSERT INTO cume_dist_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# 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)
    
    gaussdb=# DROP TABLE cume_dist_t1;
    
  • NTILE(num_buckets integer)

    Description: The NTILE function is used for equally allocating sequential data sets to the buckets whose quantity is specified by num_buckets according to num_buckets integer and allocating 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
    gaussdb=# CREATE TABLE ntile_t1(a int, b int);
    
    gaussdb=# INSERT INTO ntile_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# 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)
    
    gaussdb=# DROP TABLE ntile_t1;
    
  • LAG

    Description: The LAG function is used for generating 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 not specified, offset defaults to 1 and default to NULL. The type of the default value must be the same as that of the value value.

    Syntax:

    LAG(value any [, offset integer [, default any ]])
    LAG(value any ignore|respect nulls [, offset integer [, default any ]])
    LAG(value any [, offset integer [, default any ]]) ignore|respect nulls

    ignore|respect nulls determines whether NULL is included in the forward offset value. If not specified, the default value respect nulls is used. If ignore nulls is specified and the value is set to NULL, NULL is not included in the forward offset value. If ignore nulls is specified, the function performance deteriorates.

    Return type: same as the parameter type

    Example 1: Disable ignore nulls and set offset to 3 and default to null.

    -- Create a table and insert data into the table.
    gaussdb=# CREATE TABLE ta1 (hire_date date, last_name varchar(20), department_id int);
    CREATE TABLE
    gaussdb=# INSERT INTO ta1 values('07-DEC-02', 'Raphaely', 30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('24-JUL-05', 'Tobias',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('24-DEC-05', 'Baida',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('18-MAY-03', 'Khoo', 30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('15-NOV-06', 'Himuro',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('10-AUG-07', 'Colmenares',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('10-MAY-07', 'yq',  11);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('10-MAY-08', 'zi',  11);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('', 'yq1',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values(null, 'yq2',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('10-DEC-07', 'yq3',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values(null, null,  11);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values(null, null,  11);
    INSERT 0 1
    
    -- Call LAG and set offset to 3 and default to null.
    gaussdb=# 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)

    Example 2: Enable the ignore nulls and set offset to 3 and default to '01-JAN-00'.

    gaussdb=# SELECT hire_date, last_name, department_id, lag(hire_date, 3, '01-JAN-00') ignore nulls 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 | 2000-01-01 00:00:00
     2008-05-10 00:00:00 | zi         |            11 | 2000-01-01 00:00:00
                         |            |            11 | 2000-01-01 00:00:00
                         |            |            11 | 2000-01-01 00:00:00
     2005-12-24 00:00:00 | Baida      |            30 | 2000-01-01 00:00:00
     2007-08-10 00:00:00 | Colmenares |            30 | 2000-01-01 00:00:00
     2006-11-15 00:00:00 | Himuro     |            30 | 2000-01-01 00:00:00
     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 | 2003-05-18 00:00:00
     2007-12-10 00:00:00 | yq3        |            30 | 2003-05-18 00:00:00
    (13 rows)
    
    -- Delete the table.
    gaussdb=# DROP TABLE ta1;
    DROP TABLE
  • LEAD

    Description: The LEAD function is used for generating 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.

    Syntax:

    LEAD(value any [, offset integer [, default any ]])
    LEAD(value any ignore|respect nulls [, offset integer [, default any ]])
    LEAD(value any [, offset integer [, default any ]]) ignore|respect nulls

    ignore|respect nulls determines whether NULL is included in the backward offset value. If not specified, the default value respect nulls is used. If ignore nulls is specified and the value is set to NULL, NULL is not included in the backward offset value. If ignore nulls is specified, the function performance deteriorates.

    Return type: same as the parameter type

    Example 1: Disable ignore nulls, set offset to 2, and do not specify default.

    -- Create a table and insert data into the table.
    gaussdb=# CREATE TABLE ta1 (hire_date date, last_name varchar(20), department_id int);
    CREATE TABLE
    gaussdb=# INSERT INTO ta1 values('07-DEC-02', 'Raphaely', 30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('24-JUL-05', 'Tobias',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('24-DEC-05', 'Baida',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('18-MAY-03', 'Khoo', 30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('15-NOV-06', 'Himuro',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('10-AUG-07', 'Colmenares',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('10-MAY-07', 'yq',  11);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('10-MAY-08', 'zi',  11);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('', 'yq1',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values(null, 'yq2',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values('10-DEC-07', 'yq3',  30);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values(null, null,  11);
    INSERT 0 1
    gaussdb=# INSERT INTO ta1 values(null, null,  11);
    INSERT 0 1
    
    -- Call LEAD and set offset to 2.
    gaussdb=# 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)

    Example 2: Enable the ignore nulls and set offset to 2 and default to '01-JAN-00'.

    gaussdb=# SELECT hire_date, last_name, department_id, lead(hire_date, 2, '01-JAN-00') ignore nulls 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 | 2000-01-01 00:00:00
     2008-05-10 00:00:00 | zi         |            11 | 2000-01-01 00:00:00
                         |            |            11 | 2000-01-01 00:00:00
                         |            |            11 | 2000-01-01 00:00:00
     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 | 2007-12-10 00:00:00
     2005-07-24 00:00:00 | Tobias     |            30 | 2000-01-01 00:00:00
                         | yq1        |            30 | 2000-01-01 00:00:00
                         | yq2        |            30 | 2000-01-01 00:00:00
     2007-12-10 00:00:00 | yq3        |            30 | 2000-01-01 00:00:00
    (13 rows)
    
    -- Delete the table.
    gaussdb=# DROP TABLE ta1;
    DROP TABLE
  • 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
    gaussdb=# CREATE TABLE first_value_t1(a int, b int);
    
    gaussdb=# INSERT INTO first_value_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# 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)
    
    gaussdb=# 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
    gaussdb=# CREATE TABLE last_value_t1(a int, b int);
    
    gaussdb=# INSERT INTO last_value_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# 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)
    
    gaussdb=# DROP TABLE last_value_t1;
    
  • NTH_VALUE(value any, nth integer)

    Description: The nth row for a group is the returned value. 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
    gaussdb=# CREATE TABLE nth_value_t1(a int, b int);
    
    gaussdb=# INSERT INTO nth_value_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# 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)
    
    gaussdb=# 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

  • RATIO_TO_REPORT(column_name)

    Description: Calculates the ratio of the value in a column to the total value in the group to which the column belongs.

    Parameter: numeric type, or any type that can be implicitly converted to the numeric type.

    Return type: For input parameter types float4 and float8, the return type is of the same value type. For other input parameter types, the return type is numeric.

    When RATIO_TO_REPORT(column_name) is used together with OVER(), the input parameters of OVER() support only PRTITION BY and NULL.

    Example 1:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    gaussdb=# CREATE TABLE ratio_to_report_t1(a int, b int);
    
    gaussdb=# INSERT INTO ratio_to_report_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# SELECT a,b,RATIO_TO_REPORT(b) OVER(PARTITION BY a) FROM ratio_to_report_t1;
     a | b |    ratio_to_report     
    ---+---+------------------------
     1 | 1 |  .14285714285714285714
     1 | 1 |  .14285714285714285714
     1 | 2 |  .28571428571428571429
     1 | 3 |  .42857142857142857143
     2 | 4 |  .44444444444444444444
     2 | 5 |  .55555555555555555556
     3 | 6 | 1.00000000000000000000
    (7 rows)
    
    gaussdb=# DROP TABLE ratio_to_report_t1;
    

    Example 2: Nest this function with other functions.

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    gaussdb=# CREATE TABLE ratio_to_report_t1(a int, b int);
    
    gaussdb=# INSERT INTO ratio_to_report_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# SELECT a,b,TO_CHAR(RATIO_TO_REPORT(b) OVER(PARTITION BY a), '$999eeee') FROM ratio_to_report_t1;
     a | b | to_char 
    ---+---+---------
     1 | 1 |  1e-01
     1 | 1 |  1e-01
     1 | 2 |  3e-01
     1 | 3 |  4e-01
     2 | 4 |  4e-01
     2 | 5 |  6e-01
     3 | 6 |  1e+00
    (7 rows)
    
    gaussdb=# DROP TABLE ratio_to_report_t1;
    

    Example 3: Invoke a stored procedure.

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    19
    20
    21
    22
    23
    24
    25
    26
    27
    28
    gaussdb=# CREATE TABLE ratio_to_report_t1(a int, b int);
    
    gaussdb=# INSERT INTO ratio_to_report_t1 VALUES(1,1),(1,1),(1, 2),(1, 3),(2, 4),(2, 5),(3,6);
    
    gaussdb=# CREATE OR REPLACE PROCEDURE ratio_to_report_proc IS CURSOR cur_1 IS SELECT a,b,RATIO_TO_REPORT(b) OVER(PARTITION BY a) FROM ratio_to_report_t1;
    BEGIN
    FOR cur IN cur_1 LOOP
    RAISE INFO '%', cur.ratio_to_report;
    END LOOP;
    END;
    /
    
    gaussdb=# CALL RATIO_TO_REPORT_PROC();
    INFO:  .14285714285714285714
    INFO:  .14285714285714285714
    INFO:  .28571428571428571429
    INFO:  .42857142857142857143
    INFO:  .44444444444444444444
    INFO:  .55555555555555555556
    INFO:  1.00000000000000000000
     ratio_to_report_proc 
    ----------------------
    
    (1 row)
    
    gaussdb=# DROP PROCEDURE ratio_to_report_proc;
    
    gaussdb=# DROP TABLE ratio_to_report_t1;