Available in versions: Dev (3.19) | Latest (3.18) | 3.17 | 3.16 | 3.15 | 3.14 | 3.13 | 3.12 | 3.11 | 3.10 | 3.9

CUME_DIST

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

CUME_DIST (or cumulative distribution) works like PERCENT_RANK, but assigns ranks between 1/N and 1:

SELECT
  LANGUAGE_ID,
  cume_dist() OVER (ORDER BY LANGUAGE_ID)
FROM
  BOOK;
create.select(
         BOOK.LANGUAGE_ID,
         cumeDist().over(orderBy(BOOK.LANGUAGE_ID)))
     .from(BOOK)
     .fetch();

Producing:

+-------------+-----------+
| language_id | cume_dist |
+-------------+-----------+
|           1 |       0.5 |
|           1 |       0.5 | <-- Tied rows are both ranked first
|           2 |      0.75 |
|           4 |         1 |
+-------------+-----------+

Dialect support

This example using jOOQ:

cumeDist().over(orderBy(BOOK.ID))

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, FIREBIRD, H2, HANA, INFORMIX, MARIADB, MYSQL, ORACLE, 
-- POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB
cume_dist() OVER (ORDER BY BOOK.ID)

-- MEMSQL
(CAST(count(*) OVER (
  ORDER BY BOOK.ID
  RANGE UNBOUNDED PRECEDING
) AS decimal) / count(*) OVER (
  ORDER BY BOOK.ID
  RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
))

-- ACCESS, ASE, AURORA_MYSQL, DERBY, HSQLDB
/* UNSUPPORTED */

(These are currently generated with jOOQ 3.19, see #10141), or translate your own on our website

Feedback

Do you have any feedback about this page? We'd love to hear it!

The jOOQ Logo