@@ -4,7 +4,7 @@ WITH (timescaledb.continuous, timescaledb.materialized_only = false)
4
4
AS SELECT
5
5
pair_id,
6
6
time_bucket(' 1 day' ::interval, timestamp ) as bucket,
7
- approx_percentile (0 .5 , percentile_agg( price) )::numeric AS median_price,
7
+ percentile_disc (0 .5 ) WITHIN GROUP ( ORDER BY price)::numeric AS median_price,
8
8
COUNT (DISTINCT source) as num_sources
9
9
FROM spot_entry
10
10
GROUP BY bucket, pair_id
@@ -15,13 +15,12 @@ SELECT add_continuous_aggregate_policy('spot_price_1_day_agg',
15
15
end_offset => INTERVAL ' 1 day' ,
16
16
schedule_interval => INTERVAL ' 1 day' );
17
17
18
-
19
18
CREATE MATERIALIZED VIEW spot_price_1_week_agg
20
19
WITH (timescaledb .continuous , timescaledb .materialized_only = false)
21
20
AS SELECT
22
21
pair_id,
23
22
time_bucket(' 1 week' ::interval, timestamp ) as bucket,
24
- approx_percentile (0 .5 , percentile_agg( price) )::numeric AS median_price,
23
+ percentile_disc (0 .5 ) WITHIN GROUP ( ORDER BY price)::numeric AS median_price,
25
24
COUNT (DISTINCT source) as num_sources
26
25
FROM spot_entry
27
26
GROUP BY bucket, pair_id
@@ -38,7 +37,7 @@ WITH (timescaledb.continuous, timescaledb.materialized_only = false)
38
37
AS SELECT
39
38
pair_id,
40
39
time_bucket(' 1 day' ::interval, timestamp ) as bucket,
41
- approx_percentile (0 .5 , percentile_agg( price) )::numeric AS median_price,
40
+ percentile_disc (0 .5 ) WITHIN GROUP ( ORDER BY price)::numeric AS median_price,
42
41
COUNT (DISTINCT source) as num_sources
43
42
FROM future_entry
44
43
GROUP BY bucket, pair_id
@@ -49,13 +48,12 @@ SELECT add_continuous_aggregate_policy('future_price_1_day_agg',
49
48
end_offset => INTERVAL ' 1 day' ,
50
49
schedule_interval => INTERVAL ' 1 day' );
51
50
52
-
53
51
CREATE MATERIALIZED VIEW future_price_1_week_agg
54
52
WITH (timescaledb .continuous , timescaledb .materialized_only = false)
55
53
AS SELECT
56
54
pair_id,
57
55
time_bucket(' 1 week' ::interval, timestamp ) as bucket,
58
- approx_percentile (0 .5 , percentile_agg( price) )::numeric AS median_price,
56
+ percentile_disc (0 .5 ) WITHIN GROUP ( ORDER BY price)::numeric AS median_price,
59
57
COUNT (DISTINCT source) as num_sources
60
58
FROM future_entry
61
59
GROUP BY bucket, pair_id
@@ -66,14 +64,13 @@ SELECT add_continuous_aggregate_policy('future_price_1_week_agg',
66
64
end_offset => INTERVAL ' 1 week' ,
67
65
schedule_interval => INTERVAL ' 1 week' );
68
66
69
-
70
67
-- mainnet spot
71
68
CREATE MATERIALIZED VIEW mainnet_spot_price_1_day_agg
72
69
WITH (timescaledb .continuous , timescaledb .materialized_only = false)
73
70
AS SELECT
74
71
pair_id,
75
72
time_bucket(' 1 day' ::interval, timestamp ) as bucket,
76
- approx_percentile (0 .5 , percentile_agg( price) )::numeric AS median_price,
73
+ percentile_disc (0 .5 ) WITHIN GROUP ( ORDER BY price)::numeric AS median_price,
77
74
COUNT (DISTINCT source) as num_sources
78
75
FROM mainnet_spot_entry
79
76
GROUP BY bucket, pair_id
@@ -84,13 +81,12 @@ SELECT add_continuous_aggregate_policy('mainnet_spot_price_1_day_agg',
84
81
end_offset => INTERVAL ' 1 day' ,
85
82
schedule_interval => INTERVAL ' 1 day' );
86
83
87
-
88
84
CREATE MATERIALIZED VIEW mainnet_spot_price_1_week_agg
89
85
WITH (timescaledb .continuous , timescaledb .materialized_only = false)
90
86
AS SELECT
91
87
pair_id,
92
88
time_bucket(' 1 week' ::interval, timestamp ) as bucket,
93
- approx_percentile (0 .5 , percentile_agg( price) )::numeric AS median_price,
89
+ percentile_disc (0 .5 ) WITHIN GROUP ( ORDER BY price)::numeric AS median_price,
94
90
COUNT (DISTINCT source) as num_sources
95
91
FROM mainnet_spot_entry
96
92
GROUP BY bucket, pair_id
@@ -101,14 +97,13 @@ SELECT add_continuous_aggregate_policy('mainnet_spot_price_1_week_agg',
101
97
end_offset => INTERVAL ' 1 week' ,
102
98
schedule_interval => INTERVAL ' 1 week' );
103
99
104
-
105
100
-- mainnet future
106
101
CREATE MATERIALIZED VIEW mainnet_future_price_1_day_agg
107
102
WITH (timescaledb .continuous , timescaledb .materialized_only = false)
108
103
AS SELECT
109
104
pair_id,
110
105
time_bucket(' 1 day' ::interval, timestamp ) as bucket,
111
- approx_percentile (0 .5 , percentile_agg( price) )::numeric AS median_price,
106
+ percentile_disc (0 .5 ) WITHIN GROUP ( ORDER BY price)::numeric AS median_price,
112
107
COUNT (DISTINCT source) as num_sources
113
108
FROM mainnet_future_entry
114
109
GROUP BY bucket, pair_id
@@ -119,13 +114,12 @@ SELECT add_continuous_aggregate_policy('mainnet_future_price_1_day_agg',
119
114
end_offset => INTERVAL ' 1 day' ,
120
115
schedule_interval => INTERVAL ' 1 day' );
121
116
122
-
123
117
CREATE MATERIALIZED VIEW mainnet_future_price_1_week_agg
124
118
WITH (timescaledb .continuous , timescaledb .materialized_only = false)
125
119
AS SELECT
126
120
pair_id,
127
121
time_bucket(' 1 week' ::interval, timestamp ) as bucket,
128
- approx_percentile (0 .5 , percentile_agg( price) )::numeric AS median_price,
122
+ percentile_disc (0 .5 ) WITHIN GROUP ( ORDER BY price)::numeric AS median_price,
129
123
COUNT (DISTINCT source) as num_sources
130
124
FROM mainnet_future_entry
131
125
GROUP BY bucket, pair_id
@@ -134,4 +128,4 @@ WITH NO DATA;
134
128
SELECT add_continuous_aggregate_policy(' mainnet_future_price_1_week_agg' ,
135
129
start_offset => NULL ,
136
130
end_offset => INTERVAL ' 1 week' ,
137
- schedule_interval => INTERVAL ' 1 week' );
131
+ schedule_interval => INTERVAL ' 1 week' );
0 commit comments