-
Notifications
You must be signed in to change notification settings - Fork 50
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
Changes from 3 commits
Commits
Show all changes
4 commits
Select commit
Hold shift + click to select a range
File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,87 @@ | ||
# 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'); | ||
``` | ||
|
||
## 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 18:59:59+00','AAPL',140,20), | ||
('2023-01-11 18:23:58+00','AAPL',100,10), | ||
('2023-01-11 17:59:57+00','AAPL',133.445,NULL), | ||
('2023-01-11 17:59:55+00','PFE',47.38,2000), | ||
('2023-01-11 12:15:55+00','PFE',1,23), | ||
('2023-01-11 12:00:52+00','AAPL',29.82,NULL), | ||
('2023-01-11 11:12:12+00','PFE',47.38,14), | ||
('2023-01-11 11:01:50+00','AMZN',95.25,1000), | ||
('2023-01-11 11:01:32+00','AMZN',92,NULL), | ||
('2023-01-11 11:01:30+00','AMZN',75.225,NULL); | ||
``` | ||
## Query by-minute continuous aggregate over stock trade data for ohlc prices along with timestamps | ||
|
||
```SQL,non-transactional | ||
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 | ||
thatzopoulos marked this conversation as resolved.
Show resolved
Hide resolved
|
||
------------------------+--------+------------------------+---------+------------------------+---------+------------------------+---------+------------------------+--------- | ||
2023-01-11 12:15:00+00 | PFE | 2023-01-11 12:15:55+00 | 1 | 2023-01-11 12:15:55+00 | 1 | 2023-01-11 12:15:55+00 | 1 | 2023-01-11 12:15:55+00 | 1 | ||
2023-01-11 17:59:00+00 | PFE | 2023-01-11 17:59:55+00 | 47.38 | 2023-01-11 17:59:55+00 | 47.38 | 2023-01-11 17:59:55+00 | 47.38 | 2023-01-11 17:59:55+00 | 47.38 | ||
2023-01-11 11:01:00+00 | AMZN | 2023-01-11 11:01:30+00 | 75.225 | 2023-01-11 11:01:50+00 | 95.25 | 2023-01-11 11:01:30+00 | 75.225 | 2023-01-11 11:01:50+00 | 95.25 | ||
2023-01-11 18:59:00+00 | AAPL | 2023-01-11 18:59:59+00 | 140 | 2023-01-11 18:59:59+00 | 140 | 2023-01-11 18:59:59+00 | 140 | 2023-01-11 18:59:59+00 | 140 | ||
2023-01-11 11:12:00+00 | PFE | 2023-01-11 11:12:12+00 | 47.38 | 2023-01-11 11:12:12+00 | 47.38 | 2023-01-11 11:12:12+00 | 47.38 | 2023-01-11 11:12:12+00 | 47.38 | ||
2023-01-11 17:59:00+00 | AAPL | 2023-01-11 17:59:57+00 | 133.445 | 2023-01-11 17:59:57+00 | 133.445 | 2023-01-11 17:59:57+00 | 133.445 | 2023-01-11 17:59:57+00 | 133.445 | ||
2023-01-11 18:23:00+00 | AAPL | 2023-01-11 18:23:58+00 | 100 | 2023-01-11 18:23:58+00 | 100 | 2023-01-11 18:23:58+00 | 100 | 2023-01-11 18:23:58+00 | 100 | ||
2023-01-11 12:00:00+00 | AAPL | 2023-01-11 12:00:52+00 | 29.82 | 2023-01-11 12:00:52+00 | 29.82 | 2023-01-11 12:00:52+00 | 29.82 | 2023-01-11 12:00:52+00 | 29.82 | ||
``` | ||
|
||
## 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 | ||
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 | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I'm not actually sure we need a rollup test here, since the cagg doesn't affect the rollup behavior at all, but if we want to have it we should look at a few more columns so we can make sure it's behaving like we expect. |
||
------------------------+--------+------+------ | ||
2023-01-11 00:00:00+00 | AAPL | | 140 | ||
``` |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
I would rather see just a few interesting buckets (several points, data doesn't just go up and to the right) than many uninteresting ones, but this is good enough here.