Skip to content

Commit

Permalink
Add state_agg tests
Browse files Browse the repository at this point in the history
  • Loading branch information
syvb committed Mar 6, 2023
1 parent 4302a5b commit 692499c
Show file tree
Hide file tree
Showing 3 changed files with 455 additions and 8 deletions.
215 changes: 213 additions & 2 deletions docs/state_agg.md
Original file line number Diff line number Diff line change
Expand Up @@ -30,13 +30,17 @@ INSERT INTO states_test_4 VALUES
('2020-01-01 00:01:00+00', 2),
('2020-01-01 00:01:03+00', 51351),
('2020-01-01 00:02:00+00', -9);
CREATE TABLE states_test_5(ts TIMESTAMPTZ, state BIGINT);
CREATE TABLE states_test_5(ts TIMESTAMPTZ, state BIGINT); -- states_test with integer states
INSERT INTO states_test_5 VALUES
('2020-01-01 00:00:00+00', 4),
('2020-01-01 00:00:11+00', 51351),
('2020-01-01 00:01:00+00', 2),
('2020-01-01 00:02:03+00', 51351),
('2020-01-01 00:02:05+00', -9);
CREATE TABLE states_test_6(ts TIMESTAMPTZ, state BIGINT); -- states_test_3 with integer states
INSERT INTO states_test_6 VALUES
('2019-12-31 00:00:11+00', 456789),
('2019-12-31 00:01:00+00', 4);
```

## Functions
Expand Down Expand Up @@ -128,6 +132,15 @@ SELECT duration_in(state_agg(ts, state), 'OK', '2020-01-01 00:00:15+00', '30 sec
00:00:30
```

```SQL
SELECT duration_in(state_agg(ts, state), 51351, '2020-01-01 00:00:15+00', '1 minute 1 second') FROM states_test_4;
```
```output
duration_in
-------------
00:00:58
```

```SQL
SELECT duration_in(state_agg(ts, state), 'OK', '2020-01-01 00:00:15+00', '1 minute 1 second') FROM states_test;
```
Expand All @@ -137,6 +150,24 @@ SELECT duration_in(state_agg(ts, state), 'OK', '2020-01-01 00:00:15+00', '1 minu
00:00:58
```

```SQL
SELECT (SELECT state_agg(ts, state) FROM states_test) -> duration_in('OK'::text, '2020-01-01 00:00:15+00', '1 minute 1 second');
```
```output
?column?
-------------
00:00:58
```

```SQL
SELECT (SELECT state_agg(ts, state) FROM states_test) -> duration_in('OK');
```
```output
?column?
-------------
00:01:46
```

### into_values

```SQL
Expand Down Expand Up @@ -165,9 +196,33 @@ SELECT state, duration FROM into_int_values(
4 | 00:00:11
51351 | 00:01:46
```
```SQL
SELECT (state_agg(ts, state) -> into_values()).* FROM states_test ORDER BY state;
```
```output
state | duration
-------+----------
ERROR | 00:00:03
OK | 00:01:46
START | 00:00:11
STOP | 00:00:00
```

### state_timeline

```SQL
SELECT (state_agg(ts, state) -> state_timeline()).* FROM states_test;
```
```output
state | start_time | end_time
-------+------------------------+------------------------
START | 2020-01-01 00:00:00+00 | 2020-01-01 00:00:11+00
OK | 2020-01-01 00:00:11+00 | 2020-01-01 00:01:00+00
ERROR | 2020-01-01 00:01:00+00 | 2020-01-01 00:01:03+00
OK | 2020-01-01 00:01:03+00 | 2020-01-01 00:02:00+00
STOP | 2020-01-01 00:02:00+00 | 2020-01-01 00:02:00+00
```

```SQL
SELECT state, start_time, end_time FROM state_timeline(
(SELECT state_agg(ts, state) FROM states_test))
Expand Down Expand Up @@ -226,6 +281,17 @@ SELECT state_at(
ERROR
```
```SQL
SELECT state_at_int(
(SELECT state_agg(ts, state) FROM states_test_5),
'2020-01-01 00:01:02+00'
);
```
```output
state_at
----------
2
```
```SQL
SELECT state_at(
(SELECT state_agg(ts, state) FROM states_test),
'2020-01-01 00:01:00+00'
Expand Down Expand Up @@ -280,6 +346,14 @@ SELECT state_at(
----------
STOP
```
```SQL
SELECT (SELECT state_agg(ts, state) FROM states_test) -> state_at('2025-01-01 00:00:00+00');
```
```output
?column?
----------
STOP
```

## state_periods

Expand All @@ -298,6 +372,16 @@ start_time | end_time
2020-01-01 00:01:03+00 | 2020-01-01 00:02:00+00
```

```SQL
SELECT ((SELECT state_agg(ts, state) FROM states_test) -> state_periods('OK')).*;
```
```output
start_time | end_time
------------------------+------------------------
2020-01-01 00:00:11+00 | 2020-01-01 00:01:00+00
2020-01-01 00:01:03+00 | 2020-01-01 00:02:00+00
```

```SQL
SELECT start_time, end_time
FROM state_periods(
Expand Down Expand Up @@ -346,6 +430,41 @@ ERROR | 2020-01-01 00:01:00+00 | 2020-01-01 00:01:03+00
STOP | 2020-01-01 00:02:00+00 | 2020-01-01 00:02:00+00
```

```SQL
SELECT ((SELECT state_agg(ts, state) FROM states_test) -> interpolated_state_timeline(
'2019-12-31', '1 days',
(SELECT state_agg(ts, state) FROM states_test_3)
)).*
ORDER BY start_time;
```
```output
state | start_time | end_time
-------+------------------------+------------------------
START | 2019-12-31 00:00:00+00 | 2020-01-01 00:00:11+00
OK | 2020-01-01 00:00:11+00 | 2020-01-01 00:01:00+00
ERROR | 2020-01-01 00:01:00+00 | 2020-01-01 00:01:03+00
OK | 2020-01-01 00:01:03+00 | 2020-01-01 00:02:00+00
STOP | 2020-01-01 00:02:00+00 | 2020-01-01 00:02:00+00
```

```SQL
SELECT state, start_time, end_time FROM interpolated_state_int_timeline(
(SELECT state_agg(ts, state) FROM states_test_5),
'2019-12-31', '1 days',
(SELECT state_agg(ts, state) FROM states_test_6)
)
ORDER BY start_time;
```
```output
state | start_time | end_time
------+------------------------+-----------------------
4 | 2019-12-31 00:00:00+00 | 2020-01-01 00:00:11+00
51351 | 2020-01-01 00:00:11+00 | 2020-01-01 00:01:00+00
2 | 2020-01-01 00:01:00+00 | 2020-01-01 00:02:03+00
51351 | 2020-01-01 00:02:03+00 | 2020-01-01 00:02:05+00
-9 | 2020-01-01 00:02:05+00 | 2020-01-01 00:02:05+00
```

```SQL
SELECT state, start_time, end_time FROM interpolated_state_timeline(
(SELECT state_agg(ts, state) FROM states_test),
Expand Down Expand Up @@ -402,6 +521,15 @@ ERROR | 2020-01-01 00:01:00+00 | 2020-01-01 00:01:03+00
STOP | 2020-01-01 00:02:00+00 | 2020-01-05 00:00:00+00
```

```SQL
SELECT (state_agg(ts, state) -> state_periods('OK')).* FROM states_test;
```
```output
start_time | end_time
------------------------+------------------------
2020-01-01 00:00:11+00 | 2020-01-01 00:01:00+00
2020-01-01 00:01:03+00 | 2020-01-01 00:02:00+00
```

## interpolated_state_periods

Expand All @@ -421,6 +549,21 @@ start_time | end_time
2020-01-01 00:01:03+00 | 2020-01-01 00:02:00+00
```

```SQL
SELECT ((SELECT state_agg(ts, state) FROM states_test) -> interpolated_state_periods(
'OK',
'2019-12-31', '1 days',
(SELECT state_agg(ts, state) FROM states_test_3)
)).*
ORDER BY start_time;
```
```output
start_time | end_time
------------------------+------------------------
2020-01-01 00:00:11+00 | 2020-01-01 00:01:00+00
2020-01-01 00:01:03+00 | 2020-01-01 00:02:00+00
```

```SQL
SELECT start_time, end_time FROM interpolated_state_periods(
(SELECT state_agg(ts, state) FROM states_test),
Expand All @@ -436,6 +579,21 @@ start_time | end_time
2019-12-31 00:00:00+00 | 2020-01-01 00:00:11+00
```

```SQL
SELECT start_time, end_time FROM interpolated_state_periods(
(SELECT state_agg(ts, state) FROM states_test_5),
4,
'2019-12-31', '5 days',
(SELECT state_agg(ts, state) FROM states_test_6)
)
ORDER BY start_time;
```
```output
start_time | end_time
-----------------------+-----------------------
2019-12-31 00:00:00+00 | 2020-01-01 00:00:11+00
```

```SQL
SELECT start_time, end_time FROM interpolated_state_periods(
(SELECT state_agg(ts, state) FROM states_test),
Expand Down Expand Up @@ -468,7 +626,7 @@ start_time | end_time
2020-01-01 00:02:00+00 | 2020-01-05 00:00:00+00
```

## rolllup
## rollup

```SQL
WITH buckets AS (SELECT
Expand Down Expand Up @@ -566,3 +724,56 @@ FROM buckets;
(51351,"2020-01-01 00:00:11+00","2020-01-01 00:02:05+00")
(-9,"2020-01-01 00:02:05+00","2020-01-01 00:02:05+00")
```

## With continuous aggregate

```SQL ,non-transactional,ignore-output
CREATE TABLE email_status (
id BIGINT,
ts TIMESTAMPTZ,
status TEXT
);
SELECT create_hypertable('email_status','ts');

INSERT INTO email_status("ts", "id", "status")
VALUES
('2022-01-11 11:51:12',1,'draft'),
('2022-01-11 11:53:23',1,'queued'),
('2022-01-11 11:57:46',1,'sending'),
('2022-01-11 11:57:50',1,'sent'),
('2022-01-11 11:52:12',2,'draft'),
('2022-01-11 11:58:23',2,'queued'),
('2022-01-11 12:00:46',2,'sending'),
('2022-01-11 12:01:03',2,'bounced');
```

```SQL ,non-transactional,ignore-output
CREATE MATERIALIZED VIEW sa
WITH (timescaledb.continuous) AS
SELECT time_bucket('1 minute'::interval, ts) AS bucket,
id,
state_agg(ts, status) AS agg
FROM email_status
GROUP BY bucket, id;
```

```SQL
SELECT rollup(agg) -> duration_in('draft') FROM sa WHERE id = 1;
```
```output
?column?
----------
00:02:11
```

```SQL
SELECT (state_timeline(rollup(agg))).* FROM sa WHERE id = 2;
```
```output
state | start_time | end_time
---------+------------------------+------------------------
draft | 2022-01-11 11:52:12+00 | 2022-01-11 11:58:23+00
queued | 2022-01-11 11:58:23+00 | 2022-01-11 12:00:46+00
sending | 2022-01-11 12:00:46+00 | 2022-01-11 12:01:03+00
bounced | 2022-01-11 12:01:03+00 | 2022-01-11 12:01:03+00
```
Loading

0 comments on commit 692499c

Please sign in to comment.