Window Functions
This page unpacks QuestDB window functions and provides references.
Window functions exist within many SQL dialects. QuestDB is consistent with expected function.
What is a Window Function?
A window function performs a calculation across a set of rows that are related
to the current row. This set of related rows is called a "window", defined by an
OVER
clause that follows the window function.
In practical terms, window functions are used when you need to perform a
calculation that depends on a group of rows, but you want to retain the
individual rows in the result set. This is different from aggregate functions
like a cumulative sum
or avg
, which perform calculations on a group of rows
and return a single result.
The underlying mechanism of a window function involves three components:
-
Partitioning: The
PARTITION BY
clause divides the result set into partitions (groups of rows) upon which the window function is applied. If no partition is defined, the function treats all rows of the query result set as a single partition. -
Ordering: The
ORDER BY
clause within theOVER
clause determines the order of the rows in each partition. -
Frame Specification: This defines the set of rows included in the window, relative to the current row. For example,
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
includes all rows from the start of the partition to the current row.
Use cases for window functions are vast.
They are often used in analytics for tasks such as:
- Calculating running totals or averages
- Finding the maximum or minimum value in a sequence or partition
- Ranking items within a specific category or partition
- Calculating moving averages or cumulative sums
Window functions are tough to grok.
An analogy before we get to building:
Imagine a group of cars in a race. Each car has a number, a name, and a finish
time. If you wanted to know the average finish time, you could use an aggregate
function like avg
to calculate it. But this would only give you a single
result: the average time. You wouldn't know anything about individual cars'
times.
Now, let's say you want to know how each car's time compares to the average. Enter window functions. A window function allows you to calculate the average finish time (the window), but for each car (row) individually.
For example, you could use a window function to calculate the average finish
time for all cars, but then apply this average to each car to see if they were
faster or slower than the average. The OVER
clause in a window function is
like saying, "for each car, compare their time to the average time of all cars."
So, in essence, window functions allow you to perform calculations that consider more than just the individual row or the entire table, but a 'window' of related rows. This 'window' could be all rows with the same value in a certain column, like all cars of the same engine size, or it could be a range of rows based on some order, like the three cars who finished before and after a certain car.
This makes window functions incredibly powerful for complex calculations and analyses.
Building Window Functions
At the peak of its complexity, a window function can appear as such:
functionName OVER (
PARTITION BY columnName [, columnName ...]
ORDER BY columnName [ASC | DESC] [, columnName [ASC | DESC] ...]
RANGE | ROWS (
UNBOUNDED PRECEDING | offset PRECEDING | CURRENT ROW
| BETWEEN (UNBOUNDED PRECEDING | offset PRECEDING | CURRENT ROW)
AND (offset PRECEDING | CURRENT ROW)
)
EXCLUDE CURRENT ROW | EXCLUDE NO OTHERS
)
The broad scope of possible choices can be overwhelming. But once the options become clear, assembling valuable and performant queries is quick work.
We will break down the above into:
Base Function
This reference page demonstrates 5 base functions:
- avg()
- first_value()
- rank()
- row_number()
- Cumulative sum()
We can assemble our window functions into "blocks" so that it is easier to understand. Each block is then explained in its own small section.
The base function is the first block.
It contextualizes the "way we look through our window":
avg(price) ... (
...
)
...
)
Next we define OVER
. It is the key to assembling valuable and performant
window functions:
avg(price) OVER (
...
)
...
)
Within OVER
, we will define PARTITION BY
and ORDER BY
, as well as provide
our "Frame" clause, which details our RANGE
or ROWS
. This is the heart and
shape of our window:
avg(price) OVER (
PARTITION BY columnName [, columnName ...]
ORDER BY columnName [ASC | DESC] [, columnName [ASC | DESC] ...]
RANGE | ROWS (
UNBOUNDED PRECEDING | offset PRECEDING | CURRENT ROW
| BETWEEN (UNBOUNDED PRECEDING | offset PRECEDING | CURRENT ROW)
AND (offset PRECEDING | CURRENT ROW)
)
...
)
Finally, our exclusion clauses indicate what to omit. It's a bit like sculpting the final details into the window:
avg(price) OVER (
PARTITION BY columnName [, columnName ...]
ORDER BY columnName [ASC | DESC] [, columnName [ASC | DESC] ...]
RANGE | ROWS (
UNBOUNDED PRECEDING | offset PRECEDING | CURRENT ROW
| BETWEEN (UNBOUNDED PRECEDING | offset PRECEDING | CURRENT ROW)
AND (offset PRECEDING | CURRENT ROW)
)
EXCLUDE CURRENT ROW | EXCLUDE NO OTHERS
)
OVER Clause - PARTITION & ORDER
The OVER
clause defines how data is grouped and processed. When you set the
function ahead of OVER
, it's a bit like a "for each" operation. It is framed
as: "perform this function OVER related rows based on the following terms".
It can be used with PARTITION BY
and ORDER BY
to set unique parameters and
organize the rows. For performance reasons, if ORDER BY
is set within an
OVER
clause, it should match the base query's ORDER BY
.
"Frame" Clause - RANGE or ROWS
Window functions use a "frame" to define the subset of data the function
operates on. Two modes are available for defining this frame: RANGE
and
ROWS
.
RANGE Mode
RANGE
mode defines the window frame based on a range of values in the
ORDER BY
column. This is useful when the data has a continuous or time-based
nature.
For example, to calculate a moving average of prices over time, you might use
RANGE
mode with ORDER BY
timestamp:
SELECT symbol, price, timestamp,
avg(price) OVER (
PARTITION BY symbol
ORDER BY timestamp
RANGE BETWEEN '1' HOUR PRECEDING AND CURRENT ROW)
as moving_avg
FROM trades
This calculates the average price for each symbol, for the current row and all rows with a timestamp within the preceding hour.
ROWS Mode
ROWS
mode defines the window frame based on a specific number of rows. This is
useful when you want to consider a fixed number of rows, regardless of their
values.
For example, to calculate a moving average of the last N
prices, you might use
ROWS
mode:
SELECT symbol, price, timestamp,
avg(price) OVER (PARTITION BY symbol ORDER BY timestamp ROWS BETWEEN 3 PRECEDING AND CURRENT ROW) as moving_avg
FROM trades
This calculates the average price for each symbol, for the current row and the three preceding rows.
Common Syntax
Both RANGE
and ROWS
modes share similar syntax for defining the frame:
UNBOUNDED PRECEDING
: The window starts at the first row of the partitionvalue PRECEDING
oroffset PRECEDING
: The window starts at a specified value or number of rows before the current rowCURRENT ROW
: The window starts or ends at the current rowBETWEEN (UNBOUNDED PRECEDING | value PRECEDING | CURRENT ROW) AND (value PRECEDING | CURRENT ROW)
: The window starts and ends at specified points relative to the current row
The choice between RANGE
and ROWS
depends on the nature of your data and the
specific requirements of your calculation.
Default Frame Definition
When the frame clause is not specified, the default frame is
RANGE UNBOUNDED PRECEDING
, which includes all rows from the start of the
partition to the current row.
-
If
ORDER BY
is not present, the frame includes the entire partition, as all rows are considered equal. -
If
ORDER BY
is present, the frame includes all rows from the start of the partition to the current row. Note thatUNBOUNDED FOLLOWING
is only allowed when the frame start isUNBOUNDED PRECEDING
, which means the frame includes the entire partition.
Exclusion Option
The OVER
clause can also include an exclusion option, which determines whether
certain rows are excluded from the frame:
EXCLUDE CURRENT ROW
: Excludes the current row inROWS
mode and all rows with the sameORDER BY
value inRANGE
mode. This is equivalent to setting the frame end to1 PRECEDING
.EXCLUDE NO OTHERS
: Includes all rows in the frame. This is the default if no exclusion option is specified.
Time Units
The time units that can be used in window functions are:
day
hour
minute
second
millisecond
microsecond
Plural forms of these time units are also accepted.
avg
In the context of window functions, avg(value)
calculates the average of
value
over the set of rows defined by the window frame.
Arguments:
value
: The column of numeric values to calculate the average of.
Return value:
- The average of
value
for the rows in the window frame.
Description
When used as a window function, avg()
operates on a "window" of rows defined
by the OVER
clause. The rows in this window are determined by the
PARTITION BY
, ORDER BY
, and frame specification components of the OVER
clause.
The avg()
function respects the frame clause, meaning it only includes rows
within the specified frame in the calculation. The result is a separate average
for each row, based on the corresponding window of rows.
Note that the order of rows in the result set is not guaranteed to be the same
with each execution of the query. To ensure a consistent order, use an
ORDER BY
clause outside of the OVER
clause.
Examples:
Examples below use trades
table:
CREATE TABLE trades (
symbol SYMBOL,
price DOUBLE,
amount DOUBLE,
timestamp TIMESTAMP
) TIMESTAMP (timestamp)
PARTITION BY DAY WAL;
INSERT INTO trades(symbol, price, amount, timestamp)
VALUES
('ETH-USD', 2615.54, 0.00044, '2022-03-08 18:03:57'),
('BTC-USD', 39269.98, 0.001, '2022-03-08 18:03:57'),
('BTC-USD', 39265.31, 0.000127, '2022-03-08 18:03:58'),
('BTC-USD', 39265.31, 0.000245, '2022-03-08 18:03:58'),
('BTC-USD', 39265.31, 0.000073, '2022-03-08 18:03:58'),
('BTC-USD', 39263.28, 0.00392897, '2022-03-08 18:03:58'),
('ETH-USD', 2615.35, 0.02245868, '2022-03-08 18:03:58'),
('ETH-USD', 2615.36, 0.03244613, '2022-03-08 18:03:58'),
('BTC-USD', 39265.27, 0.00006847, '2022-03-08 18:03:58'),
('BTC-USD', 39262.42, 0.00046562, '2022-03-08 18:03:58');