Skip to content
Open
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
14 changes: 6 additions & 8 deletions documentation/cookbook/integrations/grafana/overlay-timeshift.md
Original file line number Diff line number Diff line change
Expand Up @@ -28,11 +28,10 @@ WITH sampled AS (
AND symbol = @symbol
), cumulative AS (
SELECT timestamp, symbol,
SUM(traded_value)
OVER (ORDER BY timestamp) AS cumulative_value,
SUM(volume)
OVER (ORDER BY timestamp) AS cumulative_volume
SUM(traded_value) OVER w AS cumulative_value,
SUM(volume) OVER w AS cumulative_volume
FROM sampled
WINDOW w AS (ORDER BY timestamp)
)
SELECT timestamp as time, cumulative_value/cumulative_volume AS vwap_yesterday FROM cumulative;
```
Expand All @@ -52,11 +51,10 @@ WITH sampled AS (
AND symbol = @symbol
), cumulative AS (
SELECT timestamp, symbol,
SUM(traded_value)
OVER (ORDER BY timestamp) AS cumulative_value,
SUM(volume)
OVER (ORDER BY timestamp) AS cumulative_volume
SUM(traded_value) OVER w AS cumulative_value,
SUM(volume) OVER w AS cumulative_volume
FROM sampled
WINDOW w AS (ORDER BY timestamp)
)
SELECT dateadd('d',-1,timestamp) as time, cumulative_value/cumulative_volume AS vwap_today FROM cumulative;
```
Expand Down
32 changes: 11 additions & 21 deletions documentation/cookbook/sql/finance/bollinger-bands.md
Original file line number Diff line number Diff line change
Expand Up @@ -36,15 +36,10 @@ WITH OHLC AS (
SELECT
timestamp,
close,
AVG(close) OVER (
ORDER BY timestamp
ROWS 19 PRECEDING
) AS sma20,
AVG(close * close) OVER (
ORDER BY timestamp
ROWS 19 PRECEDING
) AS avg_close_sq
AVG(close) OVER w AS sma20,
AVG(close * close) OVER w AS avg_close_sq
FROM OHLC
WINDOW w AS (ORDER BY timestamp ROWS 19 PRECEDING)
)
SELECT
timestamp,
Expand Down Expand Up @@ -74,9 +69,11 @@ The core of the Bollinger Bands calculation is the rolling standard deviation. P

**Different period lengths:**
```sql
-- 10-period Bollinger Bands (change 19 to 9)
AVG(close) OVER (ORDER BY timestamp ROWS 9 PRECEDING) AS sma10,
AVG(close * close) OVER (ORDER BY timestamp ROWS 9 PRECEDING) AS avg_close_sq
-- 10-period Bollinger Bands (change ROWS 19 to ROWS 9)
AVG(close) OVER w AS sma10,
AVG(close * close) OVER w AS avg_close_sq
...
WINDOW w AS (ORDER BY timestamp ROWS 9 PRECEDING)
```

**Different band multipliers:**
Expand Down Expand Up @@ -116,17 +113,10 @@ WITH OHLC AS (
timestamp,
symbol,
close,
AVG(close) OVER (
PARTITION BY symbol
ORDER BY timestamp
ROWS 19 PRECEDING
) AS sma20,
AVG(close * close) OVER (
PARTITION BY symbol
ORDER BY timestamp
ROWS 19 PRECEDING
) AS avg_close_sq
AVG(close) OVER w AS sma20,
AVG(close * close) OVER w AS avg_close_sq
FROM OHLC
WINDOW w AS (PARTITION BY symbol ORDER BY timestamp ROWS 19 PRECEDING)
)
SELECT
timestamp,
Expand Down
18 changes: 6 additions & 12 deletions documentation/cookbook/sql/finance/bollinger-bandwidth.md
Original file line number Diff line number Diff line change
Expand Up @@ -46,17 +46,10 @@ bands AS (
timestamp,
symbol,
close,
AVG(close) OVER (
PARTITION BY symbol
ORDER BY timestamp
ROWS BETWEEN 19 PRECEDING AND CURRENT ROW
) AS sma20,
AVG(close * close) OVER (
PARTITION BY symbol
ORDER BY timestamp
ROWS BETWEEN 19 PRECEDING AND CURRENT ROW
) AS avg_close_sq
AVG(close) OVER w AS sma20,
AVG(close * close) OVER w AS avg_close_sq
FROM daily_ohlc
WINDOW w AS (PARTITION BY symbol ORDER BY timestamp ROWS 19 PRECEDING)
),
bollinger AS (
SELECT
Expand Down Expand Up @@ -88,9 +81,10 @@ with_range AS (
upper_band,
lower_band,
bandwidth,
min(bandwidth) OVER (PARTITION BY symbol) AS min_bw,
max(bandwidth) OVER (PARTITION BY symbol) AS max_bw
min(bandwidth) OVER w AS min_bw,
max(bandwidth) OVER w AS max_bw
FROM with_bandwidth
WINDOW w AS (PARTITION BY symbol)
)
SELECT
timestamp,
Expand Down
19 changes: 10 additions & 9 deletions documentation/cookbook/sql/finance/vwap.md
Original file line number Diff line number Diff line change
Expand Up @@ -32,9 +32,9 @@ WITH sampled AS (
)
SELECT
timestamp, symbol,
SUM(traded_value) OVER (ORDER BY timestamp) /
SUM(total_volume) OVER (ORDER BY timestamp) AS vwap
FROM sampled;
SUM(traded_value) OVER w / SUM(total_volume) OVER w AS vwap
FROM sampled
WINDOW w AS (ORDER BY timestamp);
```

This query:
Expand All @@ -43,11 +43,12 @@ This query:

## How it works

The key insight is using `SUM(...) OVER (ORDER BY timestamp)` to create running totals, then dividing them directly:
The key insight is using `SUM(...) OVER w` with a named window to create running totals, then dividing them directly:

```sql
SUM(traded_value) OVER (ORDER BY timestamp) /
SUM(total_volume) OVER (ORDER BY timestamp) AS vwap
SUM(traded_value) OVER w / SUM(total_volume) OVER w AS vwap
...
WINDOW w AS (ORDER BY timestamp)
```

When using `SUM() OVER (ORDER BY timestamp)` without specifying a frame clause, QuestDB defaults to summing from the first row to the current row, which is exactly what we need for cumulative VWAP.
Expand All @@ -68,9 +69,9 @@ WITH sampled AS (
)
SELECT
timestamp, symbol,
SUM(traded_value) OVER (PARTITION BY symbol ORDER BY timestamp) /
SUM(total_volume) OVER (PARTITION BY symbol ORDER BY timestamp) AS vwap
FROM sampled;
SUM(traded_value) OVER w / SUM(total_volume) OVER w AS vwap
FROM sampled
WINDOW w AS (PARTITION BY symbol ORDER BY timestamp);
```

The `PARTITION BY symbol` ensures each symbol's VWAP is calculated independently.
Expand Down
33 changes: 21 additions & 12 deletions documentation/query/functions/window-functions/overview.md
Original file line number Diff line number Diff line change
Expand Up @@ -25,7 +25,15 @@ function_name(arguments) OVER (

Some functions (`first_value`, `last_value`, `lag`, `lead`) also support `IGNORE NULLS` or `RESPECT NULLS` before the `OVER` keyword to control null handling.

For complete syntax details including frame specifications and exclusion options, see [OVER Clause Syntax](syntax.md).
When multiple window functions share the same definition, use the `WINDOW` clause to define it once:

```sql
SELECT avg(price) OVER w, sum(amount) OVER w
FROM trades
WINDOW w AS (PARTITION BY symbol ORDER BY timestamp)
```

For complete syntax details including frame specifications, exclusion options, and named windows, see [OVER Clause Syntax](syntax.md).

:::info Window function arithmetic (9.3.1+)
Arithmetic operations on window functions (e.g., `sum(...) OVER (...) / sum(...) OVER (...)`) are supported from version 9.3.1. Earlier versions require wrapping window functions in CTEs or subqueries.
Expand Down Expand Up @@ -257,16 +265,16 @@ WITH ohlc AS (
sum(amount) AS volume
FROM trades
WHERE timestamp IN '2024-05-22' AND symbol = @symbol
SAMPLE BY 1m ALIGN TO CALENDAR
SAMPLE BY 1m
)
SELECT
ts,
symbol,
open, high, low, close, volume,
sum((high + low + close) / 3 * volume) OVER (ORDER BY ts CUMULATIVE)
/ sum(volume) OVER (ORDER BY ts CUMULATIVE) AS vwap
sum((high + low + close) / 3 * volume) OVER w / sum(volume) OVER w AS vwap
FROM ohlc
ORDER BY ts;
ORDER BY ts
WINDOW w AS (ORDER BY ts CUMULATIVE);
```

### Compare to group average
Expand All @@ -276,10 +284,11 @@ SELECT
symbol,
price,
timestamp,
avg(price) OVER (PARTITION BY symbol) AS symbol_avg,
price - avg(price) OVER (PARTITION BY symbol) AS diff_from_avg
avg(price) OVER w AS symbol_avg,
price - avg(price) OVER w AS diff_from_avg
FROM trades
WHERE timestamp IN '[$today]';
WHERE timestamp IN '[$today]'
WINDOW w AS (PARTITION BY symbol);
```

### Rank within category
Expand All @@ -303,11 +312,11 @@ WHERE timestamp IN '[$today]';
SELECT
timestamp,
price,
lag(price) OVER (ORDER BY timestamp) AS prev_price,
price - lag(price) OVER (ORDER BY timestamp) AS price_change
lag(price) OVER w AS prev_price,
price - lag(price) OVER w AS price_change
FROM trades
WHERE timestamp IN '[$today]'
AND symbol = 'BTC-USDT';
WHERE timestamp IN '[$today]' AND symbol = 'BTC-USDT'
WINDOW w AS (ORDER BY timestamp);
```

## Next steps
Expand Down
20 changes: 7 additions & 13 deletions documentation/query/functions/window-functions/reference.md
Original file line number Diff line number Diff line change
Expand Up @@ -912,24 +912,18 @@ WHERE timestamp IN '[$today]' AND symbol = 'GBPUSD';

### Trade frequency analysis

This example uses a [named window](syntax.md#named-windows-window-clause) to avoid repeating the same window definition:

```questdb-sql title="Trades per minute by side" demo
SELECT
timestamp,
symbol,
COUNT(*) OVER (
ORDER BY timestamp
RANGE BETWEEN 60000000 PRECEDING AND CURRENT ROW
) AS updates_per_min,
COUNT(CASE WHEN side = 'buy' THEN 1 END) OVER (
ORDER BY timestamp
RANGE BETWEEN 60000000 PRECEDING AND CURRENT ROW
) AS buys_per_minute,
COUNT(CASE WHEN side = 'sell' THEN 1 END) OVER (
ORDER BY timestamp
RANGE BETWEEN 60000000 PRECEDING AND CURRENT ROW
) AS sells_per_minute
COUNT(*) OVER w AS updates_per_min,
COUNT(CASE WHEN side = 'buy' THEN 1 END) OVER w AS buys_per_minute,
COUNT(CASE WHEN side = 'sell' THEN 1 END) OVER w AS sells_per_minute
FROM trades
WHERE timestamp IN '[$today]' AND symbol = 'BTC-USDT';
WHERE timestamp IN '[$today]' AND symbol = 'BTC-USDT'
WINDOW w AS (ORDER BY timestamp RANGE BETWEEN 60000000 PRECEDING AND CURRENT ROW);
```

---
Expand Down
98 changes: 94 additions & 4 deletions documentation/query/functions/window-functions/syntax.md
Original file line number Diff line number Diff line change
Expand Up @@ -332,13 +332,13 @@ WITH ohlc AS (
sum(amount) AS volume
FROM trades
WHERE timestamp IN '2024-05-22' AND symbol = @symbol
SAMPLE BY 1m ALIGN TO CALENDAR
SAMPLE BY 1m
)
SELECT
ts, open, high, low, close, volume,
sum((high + low + close) / 3 * volume) OVER (ORDER BY ts CUMULATIVE)
/ sum(volume) OVER (ORDER BY ts CUMULATIVE) AS vwap
FROM ohlc;
sum((high + low + close) / 3 * volume) OVER w / sum(volume) OVER w AS vwap
FROM ohlc
WINDOW w AS (ORDER BY ts CUMULATIVE);
```

### Frame shorthand syntax
Expand Down Expand Up @@ -463,6 +463,96 @@ LIMIT 100;
- Consider **index usage** when ordering by timestamp columns
- Narrow windows process less data than wide windows

## Named windows (WINDOW clause)

When multiple window functions share the same window definition, you can define the window once and reference it by name. This reduces repetition and improves readability.

**Syntax:**
```sql
SELECT
columns,
window_function() OVER window_name,
another_function() OVER window_name
FROM table
ORDER BY column
WINDOW window_name AS (window_definition) [, ...]
LIMIT n;
```

The `WINDOW` clause appears after `ORDER BY` and before `LIMIT`.

**Example:**
```questdb-sql title="Named window for repeated definitions" demo
SELECT
timestamp,
symbol,
price,
avg(price) OVER w AS avg_price,
min(price) OVER w AS min_price,
max(price) OVER w AS max_price
FROM trades
WHERE timestamp IN '[$today]' AND symbol = 'BTC-USDT'
WINDOW w AS (ORDER BY timestamp ROWS BETWEEN 9 PRECEDING AND CURRENT ROW)
LIMIT 100;
```

### Multiple named windows

You can define multiple windows in a single `WINDOW` clause:

```questdb-sql title="Multiple named windows" demo
SELECT
timestamp,
symbol,
price,
avg(price) OVER short_window AS avg_10,
avg(price) OVER long_window AS avg_50
FROM trades
WHERE timestamp IN '[$today]' AND symbol = 'BTC-USDT'
WINDOW
short_window AS (ORDER BY timestamp ROWS BETWEEN 9 PRECEDING AND CURRENT ROW),
long_window AS (ORDER BY timestamp ROWS BETWEEN 49 PRECEDING AND CURRENT ROW)
LIMIT 100;
```

### Mixing inline and named windows

You can use both named windows and inline `OVER (...)` definitions in the same query:

```questdb-sql title="Mixed inline and named windows" demo
SELECT
timestamp,
symbol,
price,
avg(price) OVER w AS moving_avg,
row_number() OVER (PARTITION BY symbol ORDER BY timestamp) AS seq
FROM trades
WHERE timestamp IN '[$today]' AND symbol = 'BTC-USDT'
WINDOW w AS (ORDER BY timestamp ROWS BETWEEN 9 PRECEDING AND CURRENT ROW)
LIMIT 100;
```

### Works with CTEs and subqueries

Named windows work within CTEs and subqueries:

```questdb-sql title="Named window in CTE" demo
WITH price_stats AS (
SELECT
timestamp,
symbol,
price,
avg(price) OVER w AS moving_avg,
price - avg(price) OVER w AS deviation
FROM trades
WHERE timestamp IN '[$today]' AND symbol = 'BTC-USDT'
WINDOW w AS (ORDER BY timestamp ROWS BETWEEN 19 PRECEDING AND CURRENT ROW)
)
SELECT * FROM price_stats
WHERE deviation > 10
LIMIT 100;
```

## Common pitfalls

### Window functions in WHERE
Expand Down