Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Stabilize Candlestick/OHLC #701

Merged
merged 4 commits into from
Feb 9, 2023
Merged
Show file tree
Hide file tree
Changes from 1 commit
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
4 changes: 4 additions & 0 deletions Changelog.md
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,10 @@ This changelog should be updated as part of a PR if the work is worth noting (mo
- [#660](https://github.com/timescale/timescaledb-toolkit/issues/660): Heartbeat aggregate rollup should interpolate aggregates
- [#679](https://github.com/timescale/timescaledb-toolkit/issues/679): Heartbeat agg rollup producing invalid aggregates.

#### Stabilized features

- [#701](https://github.com/timescale/timescaledb-toolkit/pull/701): Stabilize candlestick.

#### Other notable changes
- [#685](https://github.com/timescale/timescaledb-toolkit/issues/685): rollup for freq_agg and topn_agg
- [#692](https://github.com/timescale/timescaledb-toolkit/pull/692): Support specifying a range to `duration_in` to specify a time range to get states in for state aggregates
Expand Down
90 changes: 90 additions & 0 deletions docs/test_candlestick_agg.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,90 @@
# Candlestick Continuous Aggregation Tests

## Setup table
```SQL,non-transactional,ignore-output
SET TIME ZONE 'UTC';
CREATE TABLE stocks_real_time (
time TIMESTAMPTZ NOT NULL,
symbol TEXT NOT NULL,
price DOUBLE PRECISION NULL,
day_volume INT NULL
);
SELECT create_hypertable('stocks_real_time','time');
CREATE INDEX ix_symbol_time ON stocks_real_time (symbol, time DESC);
thatzopoulos marked this conversation as resolved.
Show resolved Hide resolved

CREATE TABLE company (
thatzopoulos marked this conversation as resolved.
Show resolved Hide resolved
symbol TEXT NOT NULL,
name TEXT NOT NULL
);
```

## Setup Continuous Aggs
```SQL,non-transactional,ignore-output
CREATE MATERIALIZED VIEW cs
WITH (timescaledb.continuous) AS
SELECT time_bucket('1 minute'::interval, "time") AS ts,
symbol,
candlestick_agg("time", price, day_volume) AS candlestick
FROM stocks_real_time
GROUP BY ts, symbol;
```

## Insert data into table
```SQL,non-transactional,ignore-output
INSERT INTO stocks_real_time("time","symbol","price","day_volume")
VALUES
('2023-01-11 17:59:57-06','AAPL',133.445,NULL),
('2023-01-11 17:59:55-06','PFE',47.38,NULL),
('2023-01-11 17:59:54-06','AMZN',95.225,NULL),
('2023-01-11 17:59:52-06','AAPL',29.82,NULL);
thatzopoulos marked this conversation as resolved.
Show resolved Hide resolved
```

```SQL,non-transactional,ignore-output
INSERT INTO company("symbol","name")
VALUES
('AAPL','Apple'),
('PFE','Pfizer'),
('AMZN','Amazon');
```
## Query by-minute continuous aggregate over stock trade data for ohlc prices along with timestamps

```SQL,non-transactional,ignore-output
SELECT ts,
symbol,
open_time(candlestick),
open(candlestick),
high_time(candlestick),
high(candlestick),
low_time(candlestick),
low(candlestick),
close_time(candlestick),
close(candlestick)
FROM cs;
```

```output
ts | symbol | open_time | open | high_time | high | low_time | low | close_time | close
------------------------+--------+------------------------+--------+------------------------+---------+------------------------+--------+------------------------+---------
2023-01-11 23:59:00+00 | PFE | 2023-01-11 23:59:55+00 | 47.38 | 2023-01-11 23:59:55+00 | 47.38 | 2023-01-11 23:59:55+00 | 47.38 | 2023-01-11 23:59:55+00 | 47.38
2023-01-11 23:59:00+00 | AAPL | 2023-01-11 23:59:52+00 | 29.82 | 2023-01-11 23:59:57+00 | 133.445 | 2023-01-11 23:59:52+00 | 29.82 | 2023-01-11 23:59:57+00 | 133.445
2023-01-11 23:59:00+00 | AMZN | 2023-01-11 23:59:54+00 | 95.225 | 2023-01-11 23:59:54+00 | 95.225 | 2023-01-11 23:59:54+00 | 95.225 | 2023-01-11 23:59:54+00 | 95.225
```

## Roll up your by minute continuous agg into daily buckets and return the volume weighted average price for AAPL and its high price

```SQL,non-transactional,ignore-output
SELECT
time_bucket('1 day'::interval, ts) AS daily_bucket,
symbol,
vwap(rollup(candlestick)),
high(rollup(candlestick))
thatzopoulos marked this conversation as resolved.
Show resolved Hide resolved
FROM cs
WHERE symbol = 'AAPL'
GROUP BY daily_bucket,symbol;
```

```output
daily_bucket | symbol | vwap | high
------------------------+--------+------+---------
2023-01-11 00:00:00+00 | AAPL | NULL | 133.445
```
9 changes: 8 additions & 1 deletion extension/src/accessors.rs
Original file line number Diff line number Diff line change
Expand Up @@ -89,7 +89,14 @@ accessor! { first_val() }
accessor! { last_val() }
accessor! { first_time() }
accessor! { last_time() }

accessor! { open() }
accessor! { close() }
accessor! { high() }
accessor! { low() }
accessor! { open_time() }
accessor! { high_time() }
accessor! { low_time() }
accessor! { close_time() }
// The rest are more complex, with String or other challenges. Leaving alone for now.

pg_type! {
Expand Down
Loading