Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
@@ -1,65 +1,68 @@
---
title: CUME_DIST
---
import FunctionDescription from '@site/src/components/FunctionDescription';

<FunctionDescription description="Introduced: v1.2.7"/>

Returns the cumulative distribution of a given value in a set of values. It calculates the proportion of rows that have values less than or equal to the specified value, divided by the total number of rows. Please note that the resulting value falls between 0 and 1, inclusive.

See also: [PERCENT_RANK](percent_rank.md)

## Syntax

```sql
CUME_DIST() OVER (
PARTITION BY expr, ...
ORDER BY expr [ASC | DESC], ...
)
```

## Examples

This example retrieves the students' names, scores, grades, and the cumulative distribution values (cume_dist_val) within each grade using the CUME_DIST() window function.

```sql
CREATE TABLE students (
name VARCHAR(20),
score INT NOT NULL,
grade CHAR(1) NOT NULL
);

INSERT INTO students (name, score, grade)
VALUES
('Smith', 81, 'A'),
('Jones', 55, 'C'),
('Williams', 55, 'C'),
('Taylor', 62, 'B'),
('Brown', 62, 'B'),
('Davies', 84, 'A'),
('Evans', 87, 'A'),
('Wilson', 72, 'B'),
('Thomas', 72, 'B'),
('Johnson', 100, 'A');

SELECT
name,
score,
grade,
CUME_DIST() OVER (PARTITION BY grade ORDER BY score) AS cume_dist_val
FROM
students;

name |score|grade|cume_dist_val|
--------+-----+-----+-------------+
Smith | 81|A | 0.25|
Davies | 84|A | 0.5|
Evans | 87|A | 0.75|
Johnson | 100|A | 1.0|
Taylor | 62|B | 0.5|
Brown | 62|B | 0.5|
Wilson | 72|B | 1.0|
Thomas | 72|B | 1.0|
Jones | 55|C | 1.0|
Williams| 55|C | 1.0|
```
---
title: CUME_DIST
---
import FunctionDescription from '@site/src/components/FunctionDescription';

<FunctionDescription description="Introduced: v1.2.7"/>

Calculates the cumulative distribution of each row's value. Returns the fraction of rows with values less than or equal to the current row's value.

See also: [PERCENT_RANK](percent_rank.md)

## Syntax

```sql
CUME_DIST()
OVER (
[ PARTITION BY partition_expression ]
ORDER BY sort_expression [ ASC | DESC ]
)
```

**Arguments:**
- `PARTITION BY`: Optional. Divides rows into partitions
- `ORDER BY`: Required. Determines the distribution order
- `ASC | DESC`: Optional. Sort direction (default: ASC)

**Notes:**
- Returns values between 0 and 1 (exclusive of 0, inclusive of 1)
- Formula: (number of rows ≤ current value) / (total rows)
- Always returns 1.0 for the highest value(s)
- Useful for calculating percentiles and cumulative percentages

## Examples

```sql
-- Create sample data
CREATE TABLE scores (
student VARCHAR(20),
score INT
);

INSERT INTO scores VALUES
('Alice', 95),
('Bob', 87),
('Charlie', 87),
('David', 82),
('Eve', 78);
```

**Calculate cumulative distribution (showing what percentage of students scored at or below each score):**

```sql
SELECT student, score,
CUME_DIST() OVER (ORDER BY score) AS cume_dist,
ROUND(CUME_DIST() OVER (ORDER BY score) * 100) AS cumulative_percent
FROM scores
ORDER BY score;
```

Result:
```
student | score | cume_dist | cumulative_percent
--------+-------+-----------+-------------------
Eve | 78 | 0.2 | 20
David | 82 | 0.4 | 40
Bob | 87 | 0.8 | 80
Charlie | 87 | 0.8 | 80
Alice | 95 | 1.0 | 100
Original file line number Diff line number Diff line change
Expand Up @@ -2,59 +2,96 @@
title: DENSE_RANK
---

Returns the rank of a value within a group of values, without gaps in the ranks.

The rank value starts at 1 and continues up sequentially.

If two values are the same, they have the same rank.
Assigns a rank to each row within a partition. Rows with equal values receive the same rank, with no gaps in subsequent rankings.

## Syntax

```sql
DENSE_RANK() OVER ( [ PARTITION BY <expr1> ] ORDER BY <expr2> [ ASC | DESC ] [ <window_frame> ] )
DENSE_RANK()
OVER (
[ PARTITION BY partition_expression ]
ORDER BY sort_expression [ ASC | DESC ]
)
```

**Arguments:**
- `PARTITION BY`: Optional. Divides rows into partitions
- `ORDER BY`: Required. Determines the ranking order
- `ASC | DESC`: Optional. Sort direction (default: ASC)

**Notes:**
- Ranks start from 1
- Equal values get the same rank
- No gaps in ranking sequence after ties
- Example: 1, 2, 2, 3, 4 (not 1, 2, 2, 4, 5 like RANK)

## Examples

**Create the table**
```sql
CREATE TABLE employees (
employee_id INT,
first_name VARCHAR,
last_name VARCHAR,
department VARCHAR,
salary INT
-- Create sample data
CREATE TABLE scores (
student VARCHAR(20),
subject VARCHAR(20),
score INT
);

INSERT INTO scores VALUES
('Alice', 'Math', 95),
('Alice', 'English', 87),
('Alice', 'Science', 92),
('Bob', 'Math', 85),
('Bob', 'English', 85),
('Bob', 'Science', 80),
('Charlie', 'Math', 88),
('Charlie', 'English', 85),
('Charlie', 'Science', 85);
```

**Insert data**
**Dense rank all scores (showing no gaps after ties):**

```sql
INSERT INTO employees (employee_id, first_name, last_name, department, salary) VALUES
(1, 'John', 'Doe', 'IT', 90000),
(2, 'Jane', 'Smith', 'HR', 85000),
(3, 'Mike', 'Johnson', 'IT', 82000),
(4, 'Sara', 'Williams', 'Sales', 77000),
(5, 'Tom', 'Brown', 'HR', 75000);
SELECT student, subject, score,
DENSE_RANK() OVER (ORDER BY score DESC) AS dense_rank
FROM scores
ORDER BY score DESC, student, subject;
```

**Calculating the total salary per department using DENSE_RANK**
Result:
```
student | subject | score | dense_rank
--------+---------+-------+-----------
Alice | Math | 95 | 1
Alice | Science | 92 | 2
Charlie | Math | 88 | 3
Alice | English | 87 | 4
Bob | English | 85 | 5
Bob | Math | 85 | 5
Charlie | English | 85 | 5
Charlie | Science | 85 | 5
Bob | Science | 80 | 6
```

**Dense rank scores within each student:**

```sql
SELECT
department,
SUM(salary) AS total_salary,
DENSE_RANK() OVER (ORDER BY SUM(salary) DESC) AS dense_rank
FROM
employees
GROUP BY
department;
SELECT student, subject, score,
DENSE_RANK() OVER (PARTITION BY student ORDER BY score DESC) AS subject_dense_rank
FROM scores
ORDER BY student, score DESC, subject;
```

Result:

| department | total_salary | dense_rank |
|------------|--------------|------------|
| IT | 172000 | 1 |
| HR | 160000 | 2 |
| Sales | 77000 | 3 |
```
student | subject | score | subject_dense_rank
--------+---------+-------+-------------------
Alice | Math | 95 | 1
Alice | Science | 92 | 2
Alice | English | 87 | 3
Bob | English | 85 | 1
Bob | Math | 85 | 1
Bob | Science | 80 | 2
Charlie | Math | 88 | 1
Charlie | English | 85 | 2
Charlie | Science | 85 | 2
```

Loading
Loading