Returns the cumulative distribution of a value in a group of values. The result is the number of rows preceding or peer with the row in the window ordering of the window partition divided by the total number of rows in the window partition. Thus, any tie values in the ordering will evaluate to the same distribution value.Supported Signatures
Returns the rank of a value in a group of values. This is similar to rank(), except that tie values do not produce gaps in the sequence.Examples:
examples.sql
Copy
Ask AI
SELECT name, DENSE_RANK() OVER (ORDER BY score) AS dense_rank_col FROM ( VALUES ('A', 10), ('B', 20), ('C', 20), ('D', 30)) AS t (name, score) -- value '('A', 1), ('B', 2), ('C', 2), ('D', 3)'
Returns the value at offset rows before the current row in the window partition. Offsets start at 0, which is the current row. The offset can be any scalar expression. The default offset is 1. If the offset is null, an error is raised. If the offset refers to a row that is not within the partition, the default_value is returned, or if it is not specified null is returned. The lag() function requires that the window ordering be specified. Window frame must not be specified.Examples:
examples.sql
Copy
Ask AI
SELECT name, score, LAG(score) OVER (PARTITION BY name) AS lead_score FROM ( VALUES ('A', 10), ('A', 20), ('D', 20), ('D', 30)) AS t (name, score) -- value '('A', 10, ), ('A', 20, 10), ('D', 20, ), ('D', 30, 20)'
Returns the value at offset rows after the current row in the window partition. Offsets start at 0, which is the current row. The offset can be any scalar expression. The default offset is 1. If the offset is null, an error is raised. If the offset refers to a row that is not within the partition, the default_value is returned, or if it is not specified null is returned. The lead() function requires that the window ordering be specified. Window frame must not be specified.Examples:
examples.sql
Copy
Ask AI
SELECT name, score, LEAD(score) OVER (PARTITION BY name) AS lead_score FROM ( VALUES ('A', 10), ('A', 20), ('D', 20), ('D', 30)) AS t (name, score) -- value '('A', 10, 20), ('A', 20, ), ('D', 20, 30), ('D', 30, )'
Returns the value at the specified offset from the beginning of the window. Offsets start at 1. The offset can be any scalar expression. If the offset is null or greater than the number of values in the window, null is returned. It is an error for the offset to be zero or negative.Supported Signatures
Divides the rows for each window partition into n buckets ranging from 1 to at most n. Bucket values will differ by at most 1. If the number of rows in the partition does not divide evenly into the number of buckets, then the remainder values are distributed one per bucket, starting with the first bucket.Examples:
examples.sql
Copy
Ask AI
SELECT name, NTILE(5) OVER (ORDER BY score) AS ntile_col FROM ( VALUES ('A', 10), ('A', 20), ('A', 30), ('A', 40)) AS t (name, score) -- value '('A', 1), ('A', 2), ('D', 3), ('D', 4)'
Returns the percentage ranking of a value in group of values. The result is (r - 1) / (n - 1) where r is the rank() of the row and n is the total number of rows in the window partition.Examples:
examples.sql
Copy
Ask AI
SELECT name, PERCENT_RANK() OVER (ORDER BY score) AS percent_rank_col FROM ( VALUES ('A', 10), ('B', 20), ('C', 20), ('D', 30)) AS t (name, score) -- value '('A', 0.0), ('B', 0.33333333), ('C', 0.33333333), ('D', 1.0)'
Returns the rank of a value in a group of values. The rank is one plus the number of rows preceding the row that are not peer with the row. Thus, tie values in the ordering will produce gaps in the sequence. The ranking is performed for each window partition.Examples:
examples.sql
Copy
Ask AI
SELECT name, RANK() OVER (ORDER BY score) AS rank_col FROM ( VALUES ('A', 10), ('B', 20), ('C', 20), ('D', 30)) AS t (name, score) -- value '('A', 1), ('B', 2), ('C', 2), ('D', 4)'
Returns a unique, sequential number for each row, starting with one, according to the ordering of rows within the window partition.Examples:
examples.sql
Copy
Ask AI
SELECT name, ROW_NUMBER() OVER (ORDER BY score) AS row_number_col FROM ( VALUES ('A', 10), ('B', 20), ('C', 20), ('D', 30)) AS t (name, score) -- value '('A', 1), ('B', 2), ('C', 3), ('D', 4)'