Skip to content

Commit fb3741c

Browse files
authored
fix: replace approx_percentile with perentile_disc (#179)
* ♻️ replace `approx_percentile` with `perentile_disc` * ♻️ replace `approx_percentile` with `perentile_disc` * ♻️ replace `approx_percentile` with `perentile_disc`
1 parent b5111a2 commit fb3741c

4 files changed

+39
-41
lines changed

infra/pragma-node/postgres_migrations/05-create-timescale-median-aggregates-spot.sql

+10-9
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,10 @@
1+
-- 10 seconds aggregation
12
CREATE MATERIALIZED VIEW spot_price_10_s_agg
23
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
34
AS SELECT
45
pair_id,
56
time_bucket('10 seconds'::interval, timestamp) as bucket,
6-
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,
78
COUNT(DISTINCT source) as num_sources
89
FROM spot_entry
910
GROUP BY bucket, pair_id
@@ -14,13 +15,13 @@ SELECT add_continuous_aggregate_policy('spot_price_10_s_agg',
1415
end_offset => INTERVAL '10 seconds',
1516
schedule_interval => INTERVAL '10 seconds');
1617

17-
18+
-- 1 minute aggregation
1819
CREATE MATERIALIZED VIEW spot_price_1_min_agg
1920
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
2021
AS SELECT
2122
pair_id,
2223
time_bucket('1 min'::interval, timestamp) as bucket,
23-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
24+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
2425
COUNT(DISTINCT source) as num_sources
2526
FROM spot_entry
2627
GROUP BY bucket, pair_id
@@ -31,13 +32,13 @@ SELECT add_continuous_aggregate_policy('spot_price_1_min_agg',
3132
end_offset => INTERVAL '1 min',
3233
schedule_interval => INTERVAL '1 min');
3334

34-
35+
-- 15 minutes aggregation
3536
CREATE MATERIALIZED VIEW spot_price_15_min_agg
3637
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
3738
AS SELECT
3839
pair_id,
3940
time_bucket('15 min'::interval, timestamp) as bucket,
40-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
41+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
4142
COUNT(DISTINCT source) as num_sources
4243
FROM spot_entry
4344
GROUP BY bucket, pair_id
@@ -48,13 +49,13 @@ SELECT add_continuous_aggregate_policy('spot_price_15_min_agg',
4849
end_offset => INTERVAL '15 min',
4950
schedule_interval => INTERVAL '15 min');
5051

51-
52+
-- 1 hour aggregation
5253
CREATE MATERIALIZED VIEW spot_price_1_hour_agg
5354
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
5455
AS SELECT
5556
pair_id,
5657
time_bucket('1 hour'::interval, timestamp) as bucket,
57-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
58+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
5859
COUNT(DISTINCT source) as num_sources
5960
FROM spot_entry
6061
GROUP BY bucket, pair_id
@@ -65,13 +66,13 @@ SELECT add_continuous_aggregate_policy('spot_price_1_hour_agg',
6566
end_offset => INTERVAL '1 hour',
6667
schedule_interval => INTERVAL '1 hour');
6768

68-
69+
-- 2 hours aggregation
6970
CREATE MATERIALIZED VIEW spot_price_2_hour_agg
7071
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
7172
AS SELECT
7273
pair_id,
7374
time_bucket('2 hour'::interval, timestamp) as bucket,
74-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
75+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
7576
COUNT(DISTINCT source) as num_sources
7677
FROM spot_entry
7778
GROUP BY bucket, pair_id

infra/pragma-node/postgres_migrations/06-create-timescale-median-aggregates-future.sql

+10-8
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,10 @@
1+
-- 10 seconds aggregation
12
CREATE MATERIALIZED VIEW future_price_10_s_agg
23
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
34
AS SELECT
45
pair_id,
56
time_bucket('10 seconds'::interval, timestamp) as bucket,
6-
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,
78
COUNT(DISTINCT source) as num_sources
89
FROM future_entry
910
GROUP BY bucket, pair_id
@@ -14,12 +15,13 @@ SELECT add_continuous_aggregate_policy('future_price_10_s_agg',
1415
end_offset => INTERVAL '10 seconds',
1516
schedule_interval => INTERVAL '10 seconds');
1617

18+
-- 1 minute aggregation
1719
CREATE MATERIALIZED VIEW future_price_1_min_agg
1820
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
1921
AS SELECT
2022
pair_id,
2123
time_bucket('1 min'::interval, timestamp) as bucket,
22-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
24+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
2325
COUNT(DISTINCT source) as num_sources
2426
FROM future_entry
2527
GROUP BY bucket, pair_id
@@ -30,13 +32,13 @@ SELECT add_continuous_aggregate_policy('future_price_1_min_agg',
3032
end_offset => INTERVAL '1 min',
3133
schedule_interval => INTERVAL '1 min');
3234

33-
35+
-- 15 minutes aggregation
3436
CREATE MATERIALIZED VIEW future_price_15_min_agg
3537
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
3638
AS SELECT
3739
pair_id,
3840
time_bucket('15 min'::interval, timestamp) as bucket,
39-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
41+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
4042
COUNT(DISTINCT source) as num_sources
4143
FROM future_entry
4244
GROUP BY bucket, pair_id
@@ -47,13 +49,13 @@ SELECT add_continuous_aggregate_policy('future_price_15_min_agg',
4749
end_offset => INTERVAL '15 min',
4850
schedule_interval => INTERVAL '15 min');
4951

50-
52+
-- 1 hour aggregation
5153
CREATE MATERIALIZED VIEW future_price_1_hour_agg
5254
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
5355
AS SELECT
5456
pair_id,
5557
time_bucket('1 hour'::interval, timestamp) as bucket,
56-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
58+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
5759
COUNT(DISTINCT source) as num_sources
5860
FROM future_entry
5961
GROUP BY bucket, pair_id
@@ -64,13 +66,13 @@ SELECT add_continuous_aggregate_policy('future_price_1_hour_agg',
6466
end_offset => INTERVAL '1 hour',
6567
schedule_interval => INTERVAL '1 hour');
6668

67-
69+
-- 2 hours aggregation
6870
CREATE MATERIALIZED VIEW future_price_2_hour_agg
6971
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
7072
AS SELECT
7173
pair_id,
7274
time_bucket('2 hour'::interval, timestamp) as bucket,
73-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
75+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
7476
COUNT(DISTINCT source) as num_sources
7577
FROM future_entry
7678
GROUP BY bucket, pair_id

infra/pragma-node/postgres_migrations/07-create-timescale-median-aggregates-mainnet-spot.sql

+10-9
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,10 @@
1+
-- 10 seconds aggregation
12
CREATE MATERIALIZED VIEW mainnet_spot_price_10_s_agg
23
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
34
AS SELECT
45
pair_id,
56
time_bucket('10 seconds'::interval, timestamp) as bucket,
6-
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,
78
COUNT(DISTINCT source) as num_sources
89
FROM mainnet_spot_entry
910
GROUP BY bucket, pair_id
@@ -14,13 +15,13 @@ SELECT add_continuous_aggregate_policy('mainnet_spot_price_10_s_agg',
1415
end_offset => INTERVAL '10 seconds',
1516
schedule_interval => INTERVAL '10 seconds');
1617

17-
18+
-- 1 minute aggregation
1819
CREATE MATERIALIZED VIEW mainnet_spot_price_1_min_agg
1920
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
2021
AS SELECT
2122
pair_id,
2223
time_bucket('1 min'::interval, timestamp) as bucket,
23-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
24+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
2425
COUNT(DISTINCT source) as num_sources
2526
FROM mainnet_spot_entry
2627
GROUP BY bucket, pair_id
@@ -31,13 +32,13 @@ SELECT add_continuous_aggregate_policy('mainnet_spot_price_1_min_agg',
3132
end_offset => INTERVAL '1 min',
3233
schedule_interval => INTERVAL '1 min');
3334

34-
35+
-- 15 minutes aggregation
3536
CREATE MATERIALIZED VIEW mainnet_spot_price_15_min_agg
3637
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
3738
AS SELECT
3839
pair_id,
3940
time_bucket('15 min'::interval, timestamp) as bucket,
40-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
41+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
4142
COUNT(DISTINCT source) as num_sources
4243
FROM mainnet_spot_entry
4344
GROUP BY bucket, pair_id
@@ -48,13 +49,13 @@ SELECT add_continuous_aggregate_policy('mainnet_spot_price_15_min_agg',
4849
end_offset => INTERVAL '15 min',
4950
schedule_interval => INTERVAL '15 min');
5051

51-
52+
-- 1 hour aggregation
5253
CREATE MATERIALIZED VIEW mainnet_spot_price_1_hour_agg
5354
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
5455
AS SELECT
5556
pair_id,
5657
time_bucket('1 hour'::interval, timestamp) as bucket,
57-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
58+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
5859
COUNT(DISTINCT source) as num_sources
5960
FROM mainnet_spot_entry
6061
GROUP BY bucket, pair_id
@@ -65,13 +66,13 @@ SELECT add_continuous_aggregate_policy('mainnet_spot_price_1_hour_agg',
6566
end_offset => INTERVAL '1 hour',
6667
schedule_interval => INTERVAL '1 hour');
6768

68-
69+
-- 2 hours aggregation
6970
CREATE MATERIALIZED VIEW mainnet_spot_price_2_hour_agg
7071
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
7172
AS SELECT
7273
pair_id,
7374
time_bucket('2 hour'::interval, timestamp) as bucket,
74-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
75+
percentile_disc(0.5) WITHIN GROUP (ORDER BY price)::numeric AS median_price,
7576
COUNT(DISTINCT source) as num_sources
7677
FROM mainnet_spot_entry
7778
GROUP BY bucket, pair_id

infra/pragma-node/postgres_migrations/13-add-weekly-and-daily-median-aggregates.sql

+9-15
Original file line numberDiff line numberDiff line change
@@ -4,7 +4,7 @@ WITH (timescaledb.continuous, timescaledb.materialized_only = false)
44
AS SELECT
55
pair_id,
66
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,
88
COUNT(DISTINCT source) as num_sources
99
FROM spot_entry
1010
GROUP BY bucket, pair_id
@@ -15,13 +15,12 @@ SELECT add_continuous_aggregate_policy('spot_price_1_day_agg',
1515
end_offset => INTERVAL '1 day',
1616
schedule_interval => INTERVAL '1 day');
1717

18-
1918
CREATE MATERIALIZED VIEW spot_price_1_week_agg
2019
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
2120
AS SELECT
2221
pair_id,
2322
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,
2524
COUNT(DISTINCT source) as num_sources
2625
FROM spot_entry
2726
GROUP BY bucket, pair_id
@@ -38,7 +37,7 @@ WITH (timescaledb.continuous, timescaledb.materialized_only = false)
3837
AS SELECT
3938
pair_id,
4039
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,
4241
COUNT(DISTINCT source) as num_sources
4342
FROM future_entry
4443
GROUP BY bucket, pair_id
@@ -49,13 +48,12 @@ SELECT add_continuous_aggregate_policy('future_price_1_day_agg',
4948
end_offset => INTERVAL '1 day',
5049
schedule_interval => INTERVAL '1 day');
5150

52-
5351
CREATE MATERIALIZED VIEW future_price_1_week_agg
5452
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
5553
AS SELECT
5654
pair_id,
5755
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,
5957
COUNT(DISTINCT source) as num_sources
6058
FROM future_entry
6159
GROUP BY bucket, pair_id
@@ -66,14 +64,13 @@ SELECT add_continuous_aggregate_policy('future_price_1_week_agg',
6664
end_offset => INTERVAL '1 week',
6765
schedule_interval => INTERVAL '1 week');
6866

69-
7067
--mainnet spot
7168
CREATE MATERIALIZED VIEW mainnet_spot_price_1_day_agg
7269
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
7370
AS SELECT
7471
pair_id,
7572
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,
7774
COUNT(DISTINCT source) as num_sources
7875
FROM mainnet_spot_entry
7976
GROUP BY bucket, pair_id
@@ -84,13 +81,12 @@ SELECT add_continuous_aggregate_policy('mainnet_spot_price_1_day_agg',
8481
end_offset => INTERVAL '1 day',
8582
schedule_interval => INTERVAL '1 day');
8683

87-
8884
CREATE MATERIALIZED VIEW mainnet_spot_price_1_week_agg
8985
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
9086
AS SELECT
9187
pair_id,
9288
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,
9490
COUNT(DISTINCT source) as num_sources
9591
FROM mainnet_spot_entry
9692
GROUP BY bucket, pair_id
@@ -101,14 +97,13 @@ SELECT add_continuous_aggregate_policy('mainnet_spot_price_1_week_agg',
10197
end_offset => INTERVAL '1 week',
10298
schedule_interval => INTERVAL '1 week');
10399

104-
105100
--mainnet future
106101
CREATE MATERIALIZED VIEW mainnet_future_price_1_day_agg
107102
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
108103
AS SELECT
109104
pair_id,
110105
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,
112107
COUNT(DISTINCT source) as num_sources
113108
FROM mainnet_future_entry
114109
GROUP BY bucket, pair_id
@@ -119,13 +114,12 @@ SELECT add_continuous_aggregate_policy('mainnet_future_price_1_day_agg',
119114
end_offset => INTERVAL '1 day',
120115
schedule_interval => INTERVAL '1 day');
121116

122-
123117
CREATE MATERIALIZED VIEW mainnet_future_price_1_week_agg
124118
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
125119
AS SELECT
126120
pair_id,
127121
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,
129123
COUNT(DISTINCT source) as num_sources
130124
FROM mainnet_future_entry
131125
GROUP BY bucket, pair_id
@@ -134,4 +128,4 @@ WITH NO DATA;
134128
SELECT add_continuous_aggregate_policy('mainnet_future_price_1_week_agg',
135129
start_offset => NULL,
136130
end_offset => INTERVAL '1 week',
137-
schedule_interval => INTERVAL '1 week');
131+
schedule_interval => INTERVAL '1 week');

0 commit comments

Comments
 (0)