Skip to content

Commit 0a94790

Browse files
committed
feat: cleanup migrations using postgres functions
1 parent 79d3251 commit 0a94790

File tree

50 files changed

+224
-887
lines changed

Some content is hidden

Large Commits have some content hidden by default. Use the searchbox below for content that may be hidden.

50 files changed

+224
-887
lines changed
Original file line numberDiff line numberDiff line change
@@ -1,13 +1,43 @@
11
-- Your SQL goes here
22
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
33

4+
-- SPOT entries
5+
46
CREATE TABLE entries (
57
id uuid DEFAULT uuid_generate_v4(),
68
pair_id VARCHAR NOT NULL,
7-
publisher TEXT NOT NULL,
8-
timestamp TIMESTAMPTZ NOT NULL,
99
price NUMERIC NOT NULL,
10+
timestamp TIMESTAMPTZ NOT NULL,
11+
publisher TEXT NOT NULL,
12+
publisher_signature TEXT NOT NULL,
13+
source VARCHAR NOT NULL,
1014
PRIMARY KEY (id, timestamp)
1115
);
1216

17+
CREATE UNIQUE INDEX idx_entries_unique
18+
ON entries(pair_id, source, timestamp DESC);
1319
CREATE INDEX entries_pair_id_timestamp_idx ON entries (pair_id, timestamp DESC);
20+
21+
SELECT
22+
create_hypertable('entries', 'timestamp');
23+
24+
-- FUTURE (PERP) entries
25+
26+
CREATE TABLE future_entries (
27+
id uuid DEFAULT uuid_generate_v4(),
28+
pair_id VARCHAR NOT NULL,
29+
price NUMERIC NOT NULL,
30+
timestamp TIMESTAMPTZ NOT NULL,
31+
expiration_timestamp TIMESTAMPTZ, -- can be NULL for perp contracts
32+
publisher TEXT NOT NULL,
33+
publisher_signature TEXT NOT NULL,
34+
source VARCHAR NOT NULL,
35+
PRIMARY KEY (id, timestamp)
36+
);
37+
38+
CREATE UNIQUE INDEX idx_future_entries_unique ON future_entries(pair_id, source, timestamp, expiration_timestamp);
39+
CREATE INDEX idx_future_entries_pair_id_timestamp ON future_entries (pair_id, timestamp DESC);
40+
CREATE INDEX idx_future_entries_pair_id_timestamp_expiration_timestamp ON future_entries (pair_id, expiration_timestamp, timestamp DESC);
41+
42+
SELECT
43+
create_hypertable('future_entries', 'timestamp');

pragma-entities/migrations/2023-10-12-005433_add_source/down.sql

-3
This file was deleted.

pragma-entities/migrations/2023-10-12-005433_add_source/up.sql

-3
This file was deleted.

pragma-entities/migrations/2023-10-12-232125_add_publishers_table/up.sql

+2-1
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@ CREATE TABLE publishers (
44
name VARCHAR NOT NULL,
55
master_key VARCHAR NOT NULL,
66
active_key VARCHAR NOT NULL,
7-
active BOOLEAN NOT NULL,
7+
account_address VARCHAR NOT NULL DEFAULT '',
8+
active BOOLEAN NOT NULL DEFAULT true,
89
PRIMARY KEY (id)
910
);

pragma-entities/migrations/2023-10-16-233310_add_account_address/up.sql

-3
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,4 @@
11
-- Your SQL goes here
2-
ALTER TABLE publishers
3-
ADD COLUMN account_address VARCHAR NOT NULL DEFAULT '';
4-
52
INSERT INTO publishers (name, master_key, active_key, active, account_address)
63
VALUES (
74
'PRAGMA',

pragma-entities/migrations/2023-10-25-134954_add_currencies_table/up.sql

-23
This file was deleted.

pragma-entities/migrations/2023-11-24-185951_add_source_index/down.sql

-2
This file was deleted.

pragma-entities/migrations/2023-11-24-185951_add_source_index/up.sql

-3
This file was deleted.

pragma-entities/migrations/2023-12-29-052754_add_hypertable_entries/down.sql

-2
This file was deleted.

pragma-entities/migrations/2023-12-29-052754_add_hypertable_entries/up.sql

-2
This file was deleted.
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,26 @@
11
-- This file should undo anything in `up.sql`
2+
3+
-- Drop spot price aggregates
4+
DROP MATERIALIZED VIEW IF EXISTS price_100_ms_agg;
5+
DROP MATERIALIZED VIEW IF EXISTS price_1_s_agg;
6+
DROP MATERIALIZED VIEW IF EXISTS price_5_s_agg;
27
DROP MATERIALIZED VIEW IF EXISTS price_1_min_agg;
38
DROP MATERIALIZED VIEW IF EXISTS price_15_min_agg;
4-
DROP MATERIALIZED VIEW IF EXISTS price_1_h_agg;
9+
DROP MATERIALIZED VIEW IF EXISTS price_1_h_agg;
10+
DROP MATERIALIZED VIEW IF EXISTS price_2_h_agg;
11+
DROP MATERIALIZED VIEW IF EXISTS price_1_day_agg;
12+
DROP MATERIALIZED VIEW IF EXISTS price_1_week_agg;
13+
14+
-- Drop future price aggregates
15+
DROP MATERIALIZED VIEW IF EXISTS price_100_ms_agg_future;
16+
DROP MATERIALIZED VIEW IF EXISTS price_1_s_agg_future;
17+
DROP MATERIALIZED VIEW IF EXISTS price_5_s_agg_future;
18+
DROP MATERIALIZED VIEW IF EXISTS price_1_min_agg_future;
19+
DROP MATERIALIZED VIEW IF EXISTS price_15_min_agg_future;
20+
DROP MATERIALIZED VIEW IF EXISTS price_1_h_agg_future;
21+
DROP MATERIALIZED VIEW IF EXISTS price_2_h_agg_future;
22+
DROP MATERIALIZED VIEW IF EXISTS price_1_day_agg_future;
23+
DROP MATERIALIZED VIEW IF EXISTS price_1_week_agg_future;
24+
25+
-- Drop the function
26+
DROP FUNCTION IF EXISTS create_continuous_aggregate;
Original file line numberDiff line numberDiff line change
@@ -1,49 +1,50 @@
1-
-- Your SQL goes here
2-
CREATE MATERIALIZED VIEW price_1_min_agg
3-
WITH (timescaledb.continuous, timescaledb.materialized_only = true)
4-
AS SELECT
5-
pair_id,
6-
time_bucket('1 min'::interval, timestamp) as bucket,
7-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
8-
COUNT(DISTINCT source) as num_sources
9-
FROM entries
10-
GROUP BY bucket, pair_id
11-
WITH NO DATA;
1+
CREATE OR REPLACE FUNCTION create_continuous_aggregate(
2+
p_name text,
3+
p_interval interval,
4+
p_start_offset interval,
5+
p_table_name text
6+
)
7+
RETURNS void AS $$
8+
BEGIN
9+
EXECUTE format('
10+
CREATE MATERIALIZED VIEW %s
11+
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
12+
AS SELECT
13+
pair_id,
14+
time_bucket($1::interval, timestamp) as bucket,
15+
(percentile_cont(0.5) WITHIN GROUP (ORDER BY price))::numeric(1000,0) AS median_price,
16+
COUNT(DISTINCT source) as num_sources
17+
FROM %I
18+
GROUP BY bucket, pair_id
19+
WITH NO DATA;', p_name, p_interval, p_table_name);
1220

13-
SELECT add_continuous_aggregate_policy('price_1_min_agg',
14-
start_offset => NULL,
15-
end_offset => INTERVAL '1 min',
16-
schedule_interval => INTERVAL '1 min');
21+
EXECUTE format('
22+
SELECT add_continuous_aggregate_policy(''%s'',
23+
start_offset => $1,
24+
end_offset => $2,
25+
schedule_interval => $3);', p_name, p_start_offset, p_interval, p_interval);
26+
END;
27+
$$ LANGUAGE plpgsql;
1728

18-
CREATE MATERIALIZED VIEW price_15_min_agg
19-
WITH (timescaledb.continuous, timescaledb.materialized_only = true)
20-
AS SELECT
21-
pair_id,
22-
time_bucket('15 min'::interval, timestamp) as bucket,
23-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
24-
COUNT(DISTINCT source) as num_sources
25-
FROM entries
26-
GROUP BY bucket, pair_id
27-
WITH NO DATA;
29+
-- Spot entries aggregates
30+
SELECT create_continuous_aggregate('price_100_ms_agg', '100 milliseconds'::interval, '300 milliseconds'::interval, 'entries');
31+
SELECT create_continuous_aggregate('price_1_s_agg', '1 second'::interval, '3 seconds'::interval, 'entries');
32+
SELECT create_continuous_aggregate('price_5_s_agg', '5 seconds'::interval, '15 seconds'::interval, 'entries');
33+
SELECT create_continuous_aggregate('price_1_min_agg', '1 minute'::interval, '3 minutes'::interval, 'entries');
34+
SELECT create_continuous_aggregate('price_15_min_agg', '15 minutes'::interval, '45 minutes'::interval, 'entries');
35+
SELECT create_continuous_aggregate('price_1_h_agg', '1 hour'::interval, '3 hours'::interval, 'entries');
36+
SELECT create_continuous_aggregate('price_2_h_agg', '2 hours'::interval, '6 hours'::interval, 'entries');
37+
SELECT create_continuous_aggregate('price_1_day_agg', '1 day'::interval, '3 days'::interval, 'entries');
38+
SELECT create_continuous_aggregate('price_1_week_agg', '1 week'::interval, '3 weeks'::interval, 'entries');
2839

29-
SELECT add_continuous_aggregate_policy('price_15_min_agg',
30-
start_offset => NULL,
31-
end_offset => INTERVAL '15 min',
32-
schedule_interval => INTERVAL '15 min');
33-
34-
CREATE MATERIALIZED VIEW price_1_h_agg
35-
WITH (timescaledb.continuous, timescaledb.materialized_only = true)
36-
AS SELECT
37-
pair_id,
38-
time_bucket('1 hour'::interval, timestamp) as bucket,
39-
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
40-
COUNT(DISTINCT source) as num_sources
41-
FROM entries
42-
GROUP BY bucket, pair_id
43-
WITH NO DATA;
44-
45-
SELECT add_continuous_aggregate_policy('price_1_h_agg',
46-
start_offset => NULL,
47-
end_offset => INTERVAL '1 hour',
48-
schedule_interval => INTERVAL '1 hour');
40+
-- Future entries aggregates
41+
SELECT create_continuous_aggregate('price_100_ms_agg_future', '100 milliseconds'::interval, '300 milliseconds'::interval, 'future_entries');
42+
SELECT create_continuous_aggregate('price_1_s_agg_future', '1 second'::interval, '3 seconds'::interval, 'future_entries');
43+
SELECT create_continuous_aggregate('price_5_s_agg_future', '5 seconds'::interval, '15 seconds'::interval, 'future_entries');
44+
SELECT create_continuous_aggregate('price_1_min_agg_future', '1 minute'::interval, '3 minutes'::interval, 'future_entries');
45+
SELECT create_continuous_aggregate('price_15_min_agg_future', '15 minutes'::interval, '45 minutes'::interval, 'future_entries');
46+
SELECT create_continuous_aggregate('price_1_h_agg_future', '1 hour'::interval, '3 hours'::interval, 'future_entries');
47+
SELECT create_continuous_aggregate('price_2_h_agg_future', '2 hours'::interval, '6 hours'::interval, 'future_entries');
48+
SELECT create_continuous_aggregate('price_1_day_agg_future', '1 day'::interval, '3 days'::interval, 'future_entries');
49+
SELECT create_continuous_aggregate('price_1_week_agg_future', '1 week'::interval, '3 weeks'::interval, 'future_entries');
4950

pragma-entities/migrations/2024-01-12-095822_add_realtime_agg/down.sql

-4
This file was deleted.

pragma-entities/migrations/2024-01-12-095822_add_realtime_agg/up.sql

-4
This file was deleted.
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,18 @@
11
-- This file should undo anything in `up.sql`
2-
DROP MATERIALIZED VIEW IF EXISTS one_day_candle;
3-
DROP MATERIALIZED VIEW IF EXISTS one_hour_candle;
4-
DROP MATERIALIZED VIEW IF EXISTS fifteen_minute_candle;
5-
DROP MATERIALIZED VIEW IF EXISTS five_minute_candle;
6-
DROP MATERIALIZED VIEW IF EXISTS one_minute_candle;
2+
3+
-- Drop spot candlestick views
4+
DROP MATERIALIZED VIEW IF EXISTS candle_1_min;
5+
DROP MATERIALIZED VIEW IF EXISTS candle_5_min;
6+
DROP MATERIALIZED VIEW IF EXISTS candle_15_min;
7+
DROP MATERIALIZED VIEW IF EXISTS candle_1_h;
8+
DROP MATERIALIZED VIEW IF EXISTS candle_1_day;
9+
10+
-- Drop future candlestick views
11+
DROP MATERIALIZED VIEW IF EXISTS candle_1_min_future;
12+
DROP MATERIALIZED VIEW IF EXISTS candle_5_min_future;
13+
DROP MATERIALIZED VIEW IF EXISTS candle_15_min_future;
14+
DROP MATERIALIZED VIEW IF EXISTS candle_1_h_future;
15+
DROP MATERIALIZED VIEW IF EXISTS candle_1_day_future;
16+
17+
-- Drop the function
18+
DROP FUNCTION IF EXISTS create_candlestick_view;

0 commit comments

Comments
 (0)