Documentation

SQL window functions

InfluxDB 3 Core is in Public Beta

InfluxDB 3 Core is in public beta and available for testing and feedback, but is not meant for production use yet. Both the product and this documentation are works in progress. We welcome and encourage your input about your experience with the beta and invite you to join our public channels for updates and to share feedback.

Beta expectations and recommendations

Window functions let you calculate running totals, moving averages, or other aggregate-like results without collapsing rows into groups. They perform their calculations over a “window” of rows, which you can partition and order in various ways, and return a calculated value for each row in the set.

Unlike non-window aggregate functions that combine each group into a single row, window functions preserve each row’s identity and calculate an additional value for every row in the partition.

For example, the following query uses the Home sensor sample data and returns each temperature reading with the average temperature per room over the queried time range:

SELECT
  time,
  room,
  temp,
  avg(temp) OVER (PARTITION BY room) AS avg_room_temp
FROM
  home
WHERE
  time >= '2025-03-29T08:00:00Z'
  AND time <= '2025-03-29T09:00:00Z'
ORDER BY
  room,
  time
  • Copy
  • Fill window
timeroomtempavg_room_temp
2025-03-29T08:00:00Kitchen21.022.0
2025-03-29T09:00:00Kitchen23.022.0
2025-03-29T08:00:00Living Room21.121.25
2025-03-29T09:00:00Living Room21.421.25

Window frames

As window functions operate on a row, there is a set of rows in the row’s partition that the window function uses to perform the operation. This set of rows is called the window frame. Window frame boundaries can be defined using RANGE, ROW, or GROUPS frame units, each relative to the current row–for example:

SELECT
  time,
  temp,
  avg(temp) OVER (
    ORDER BY time
    RANGE INTERVAL '3 hours' PRECEDING
  ) AS 3h_moving_avg
FROM home
WHERE room = 'Kitchen'
  • Copy
  • Fill window
SELECT
  time,
  temp,
  avg(temp) OVER (
    ROWS 3 PRECEDING
  ) AS moving_avg
FROM home
WHERE room = 'Kitchen'
  • Copy
  • Fill window
SELECT
  time,
  room,
  temp,
  avg(temp) OVER (
    ORDER BY room
    GROUPS 1 PRECEDING
  ) AS moving_avg
FROM home
  • Copy
  • Fill window

For more information about how window frames work, see the frame clause.

If you don’t specify window frames, window functions use all rows in the current partition to perform their operation.

function([expr])
  OVER(
    [PARTITION BY expr[, ]]
    [ORDER BY expr [ ASC | DESC ][, ]]
    [ frame_clause ]
    )
  • Copy
  • Fill window

OVER clause

Window functions use an OVER clause that directly follows the window function’s
name and arguments.
The OVER clause syntactically distinguishes a window
function from a non-window or aggregate function and defines how to group and order rows for the window operation.

PARTITION BY clause

The PARTITION BY clause in the OVER clause divides the rows into groups, or partitions, that share the same values of the PARTITION BY expressions. The window function operates on all the rows in the same partition as the current row.

ORDER BY clause

The ORDER BY clause inside of the OVER clause controls the order that the window function processes rows in each partition. When a window clause contains an ORDER BY clause, the window frame boundaries may be explicit or implicit, limiting a window frame size in both directions relative to the current row.

The ORDER BY clause in an OVER clause determines the processing order for rows in each partition and is separate from the ORDER BY clause of the query.

Frame clause

The frame clause defines window frame boundaries and can be one of the following:

{ RANGE | ROWS | GROUPS } frame_start
{ RANGE | ROWS | GROUPS } BETWEEN frame_start AND frame_end
  • Copy
  • Fill window

Frame units

When defining window frames, you can use one of the following frame units:

RANGE

Defines frame boundaries using rows with values for columns specified in the ORDER BY clause within a value range relative to the current row value.

When using RANGE frame units, you must include an ORDER BY clause with exactly one column.

The offset is the difference between the current row value and surrounding row values. RANGE supports the following offset types:

  • Numeric (non-negative)
  • Numeric string (non-negative)
  • Interval

See how RANGE frame units work with numeric offsets

See how RANGE frame units work with interval offsets

ROWS

Defines window frame boundaries using row positions relative to the current row. The offset is the difference in row position from the current row. ROWS supports the following offset types:

  • Numeric (non-negative)
  • Numeric string (non-negative)

See how ROWS frame units work

GROUPS

Defines window frame boundaries using row groups. Rows with the same values for the columns in the ORDER BY clause comprise a row group.

When using GROUPS frame units, include an ORDER BY clause.

The offset is the difference in row group position relative to the current row group. GROUPS supports the following offset types:

  • Numeric (non-negative)
  • Numeric string (non-negative)

See how GROUPS frame units work

Frame boundaries

Frame boundaries (frame_start and frame_end) define the boundaries of each frame that the window function operates on.

UNBOUNDED PRECEDING

Starts at the first row of the partition and ends at the current row.

UNBOUNDED PRECEDING
  • Copy
  • Fill window
offset PRECEDING

Starts at offset frame units before the current row and ends at the current row. For example, 3 PRECEDING includes 3 rows before the current row.

<offset> PRECEDING
  • Copy
  • Fill window
CURRENT ROW

Both starts and ends at the current row when used as a boundary.

CURRENT ROW
  • Copy
  • Fill window
offset FOLLOWING

Starts at the current row and ends at offset frame units after the current row. For example, 3 FOLLOWING includes 3 rows after the current row.

<offset> FOLLOWING
  • Copy
  • Fill window
UNBOUNDED FOLLOWING

Starts at the current row and ends at the last row of the partition.

offset FOLLOWING

Use a specified offset of frame units after the current row as a frame boundary.

offset FOLLOWING
  • Copy
  • Fill window
UNBOUNDED FOLLOWING

Use the current row to the end of the current partition the frame boundary.

UNBOUNDED FOLLOWING
  • Copy
  • Fill window

WINDOW clause

Use the WINDOW clause to define a reusable alias for a window specification. This is useful when multiple window functions in your query share the same window definition.

Instead of repeating the same OVER clause for each function, define the window once and reference it by alias–for example:

SELECT
  sum(net_gain) OVER w,
  avg(net_net) OVER w
FROM
  finance
WINDOW w AS ( PARTITION BY ticker ORDER BY time DESC);
  • Copy
  • Fill window

Aggregate functions

All aggregate functions can be used as window functions.

Ranking Functions

cume_dist

Returns the cumulative distribution of a value within a group of values. The returned value is greater than 0 and less than or equal to 1 and represents the relative rank of the value in the set of values. The ORDER BY clause in the OVER clause is used to correctly calculate the cumulative distribution of the current row value.

cume_dist()
  • Copy
  • Fill window

When using cume_dist, include an ORDER BY clause in the OVER clause.

View cume_dist query example

dense_rank

Returns the rank of the current row in its partition. Ranking is consecutive; assigns duplicate values the same rank number and the rank sequence continues with the next distinct value (unlike rank()).

The ORDER BY clause in the OVER clause determines ranking order.

dense_rank()
  • Copy
  • Fill window

View dense_rank query example

Compare dense_rank, rank, and row_number functions

ntile

Distributes the rows in an ordered partition into the specified number of groups. Each group is numbered, starting at one. For each row, ntile returns the group number to which the row belongs. Group numbers range from 1 to the expression value, dividing the partition as equally as possible. The ORDER BY clause in the OVER clause determines ranking order.

ntile(expression)
  • Copy
  • Fill window
Arguments
  • expression: An integer. The number of groups to split the partition into.

View ntile query example

percent_rank

Returns the percentage rank of the current row within its partition. The returned value is between 0 and 1, computed as:

(rank - 1) / (total_rows - 1)
  • Copy
  • Fill window

The ORDER BY clause in the OVER clause determines the ranking order.

percent_rank()
  • Copy
  • Fill window

View percent_rank query example

rank

Returns the rank of the current row in its partition. For duplicate values, rank assigns them the same rank number, skips subsequent ranks (unlike dense_rank()), and then continues ranking with the next distinct value.

The ORDER BY clause in the OVER clause determines ranking order.

rank()
  • Copy
  • Fill window

View rank query example

Compare dense_rank, rank, and row_number functions

row_number

Returns the position of the current row in its partition, counting from 1. The ORDER BY clause in the OVER clause determines row order.

row_number()
  • Copy
  • Fill window

View row_number query example

Compare dense_rank, rank, and row_number functions

Analytical Functions

first_value

Returns the value from the first row of the window frame.

first_value(expression)
  • Copy
  • Fill window
Arguments
  • expression: Expression to operate on. Can be a constant, column, or function, and any combination of arithmetic operators.

last_value

View first_value query example

lag

Returns the value from the row that is at the specified offset before the current row in the partition. If the offset row is outside the partition, the function returns the specified default.

lag(expression, offset, default)
  • Copy
  • Fill window
Arguments
  • expression: Expression to operate on. Can be a constant, column, or function, and any combination of arithmetic or string operators.
  • offset: How many rows before the current row to retrieve the value of expression from. Default is 1.
  • default: The default value to return if the offset is in the partition. Must be of the same type as expression.

lead

View lag query example

last_value

Returns the value from the last row of the window frame.

last_value(expression)
  • Copy
  • Fill window
Arguments
  • expression: Expression to operate on. Can be a constant, column, or function, and any combination of arithmetic operators.

first_value

View last_value query example

lead

Returns the value from the row that is at the specified offset after the current row in the partition. If the offset row is outside the partition, the function returns the specified default.

lead(expression, offset, default)
  • Copy
  • Fill window
Arguments
  • expression: Expression to operate on. Can be a constant, column, or function, and any combination of arithmetic or string operators.
  • offset: How many rows before the current row to retrieve the value of expression from. Default is 1.
  • default: The default value to return if the offset is in the partition. Must be of the same type as expression.

lag

View lead query example

nth_value

Returns the value from the row that is the nth row of the window frame (counting from 1). If the nth row doesn’t exist, the function returns null.

nth_value(expression, n)
  • Copy
  • Fill window
Arguments
  • expression: The expression to operator on. Can be a constant, column, or function, and any combination of arithmetic or string operators.
  • n: Specifies the row number in the current frame and partition to reference.

View lead query example


Was this page helpful?

Thank you for your feedback!


The future of Flux

Flux is going into maintenance mode. You can continue using it as you currently are without any changes to your code.

Read more

InfluxDB 3 Core and Enterprise are now in Beta

InfluxDB 3 Core and Enterprise are now available for beta testing, available under MIT or Apache 2 license.

InfluxDB 3 Core is a high-speed, recent-data engine that collects and processes data in real-time, while persisting it to local disk or object storage. InfluxDB 3 Enterprise is a commercial product that builds on Core’s foundation, adding high availability, read replicas, enhanced security, and data compaction for faster queries. A free tier of InfluxDB 3 Enterprise will also be available for at-home, non-commercial use for hobbyists to get the full historical time series database set of capabilities.

For more information, check out: