Skip to content

Commit 72195af

Browse files
committed
feat: compression migration using hypercore
1 parent 0a94790 commit 72195af

File tree

3 files changed

+142
-0
lines changed
  • pragma-entities/migrations

3 files changed

+142
-0
lines changed

pragma-entities/migrations/2024-01-12-135355_add_candlestick_views/up.sql

+2
Original file line numberDiff line numberDiff line change
@@ -29,13 +29,15 @@ END;
2929
$$ LANGUAGE plpgsql;
3030

3131
-- Spot entries candlesticks
32+
SELECT create_candlestick_view('candle_10_s', '10 seconds'::interval, '30 seconds'::interval, 'price_1_s_agg');
3233
SELECT create_candlestick_view('candle_1_min', '1 minute'::interval, '3 minutes'::interval, 'price_1_s_agg');
3334
SELECT create_candlestick_view('candle_5_min', '5 minutes'::interval, '15 minutes'::interval, 'price_10_s_agg');
3435
SELECT create_candlestick_view('candle_15_min', '15 minutes'::interval, '45 minutes'::interval, 'price_10_s_agg');
3536
SELECT create_candlestick_view('candle_1_h', '1 hour'::interval, '3 hours'::interval, 'price_10_s_agg');
3637
SELECT create_candlestick_view('candle_1_day', '1 day'::interval, '3 days'::interval, 'price_10_s_agg');
3738

3839
-- Future entries candlesticks
40+
SELECT create_candlestick_view('candle_10_s_future', '10 seconds'::interval, '30 seconds'::interval, 'price_1_s_agg_future');
3941
SELECT create_candlestick_view('candle_1_min_future', '1 minute'::interval, '3 minutes'::interval, 'price_1_s_agg_future');
4042
SELECT create_candlestick_view('candle_5_min_future', '5 minutes'::interval, '15 minutes'::interval, 'price_10_s_agg_future');
4143
SELECT create_candlestick_view('candle_15_min_future', '15 minutes'::interval, '45 minutes'::interval, 'price_10_s_agg_future');
Original file line numberDiff line numberDiff line change
@@ -1 +1,57 @@
11
-- This file should undo anything in `up.sql`
2+
3+
-- Function to remove compression policies from continuous aggregates
4+
CREATE OR REPLACE FUNCTION remove_compression_from_continuous_aggregates()
5+
RETURNS void AS $$
6+
DECLARE
7+
view_name text;
8+
BEGIN
9+
FOR view_name IN
10+
SELECT format('%s', unnest(ARRAY[
11+
-- Sub-minute aggregates
12+
'price_100_ms_agg', 'price_1_s_agg', 'price_5_s_agg',
13+
'price_100_ms_agg_future', 'price_1_s_agg_future', 'price_5_s_agg_future',
14+
'candle_10_s', 'candle_10_s_future',
15+
16+
-- 1-15min aggregates
17+
'price_1_min_agg', 'price_15_min_agg',
18+
'price_1_min_agg_future', 'price_15_min_agg_future',
19+
'candle_1_min', 'candle_5_min', 'candle_15_min',
20+
'candle_1_min_future', 'candle_5_min_future', 'candle_15_min_future',
21+
'twap_1_min_agg', 'twap_5_min_agg', 'twap_15_min_agg',
22+
'twap_1_min_agg_future', 'twap_5_min_agg_future', 'twap_15_min_agg_future',
23+
24+
-- 1-2h aggregates
25+
'price_1_h_agg', 'price_2_h_agg',
26+
'price_1_h_agg_future', 'price_2_h_agg_future',
27+
'candle_1_h', 'candle_1_h_future',
28+
'twap_1_h_agg', 'twap_2_h_agg',
29+
'twap_1_h_agg_future', 'twap_2_h_agg_future',
30+
31+
-- Daily aggregates
32+
'price_1_day_agg', 'price_1_day_agg_future',
33+
'candle_1_day', 'candle_1_day_future',
34+
'twap_1_day_agg', 'twap_1_day_agg_future',
35+
36+
-- Weekly aggregates
37+
'price_1_week_agg', 'price_1_week_agg_future'
38+
]))
39+
LOOP
40+
-- Remove compression policy
41+
CALL remove_compression_policy(view_name, if_exists => true);
42+
-- Disable columnstore
43+
EXECUTE format('ALTER MATERIALIZED VIEW %I SET (timescaledb.enable_columnstore = false)', view_name);
44+
END LOOP;
45+
END;
46+
$$ LANGUAGE plpgsql;
47+
48+
-- Remove compression policies from all continuous aggregates
49+
SELECT remove_compression_from_continuous_aggregates();
50+
51+
-- Drop the functions
52+
DROP FUNCTION IF EXISTS add_compression_to_continuous_aggregates;
53+
DROP FUNCTION IF EXISTS remove_compression_from_continuous_aggregates;
54+
55+
-- Remove compression from base tables
56+
ALTER TABLE entries SET (timescaledb.enable_columnstore = false);
57+
ALTER TABLE future_entries SET (timescaledb.enable_columnstore = false);
Original file line numberDiff line numberDiff line change
@@ -1 +1,85 @@
11
-- Your SQL goes here
2+
3+
-- Enable hypercore
4+
ALTER TABLE entries SET (
5+
timescaledb.enable_columnstore = true,
6+
timescaledb.segmentby = 'pair_id');
7+
8+
ALTER TABLE future_entries SET (
9+
timescaledb.enable_columnstore = true,
10+
timescaledb.segmentby = 'pair_id'
11+
);
12+
13+
-- Add compression policies
14+
CALL add_columnstore_policy('entries', after => INTERVAL '1d');
15+
CALL add_columnstore_policy('future_entries', after => INTERVAL '1d');
16+
17+
-- Function to add columnstore policies to continuous aggregates
18+
CREATE OR REPLACE FUNCTION add_compression_to_continuous_aggregates()
19+
RETURNS void AS $$
20+
DECLARE
21+
view_name text;
22+
compress_after interval;
23+
BEGIN
24+
FOR view_name IN
25+
SELECT format('%s', unnest(ARRAY[
26+
-- Sub-minute aggregates
27+
'price_100_ms_agg', 'price_1_s_agg', 'price_5_s_agg',
28+
'price_100_ms_agg_future', 'price_1_s_agg_future', 'price_5_s_agg_future',
29+
'candle_10_s', 'candle_10_s_future',
30+
31+
-- 1-15min aggregates
32+
'price_1_min_agg', 'price_15_min_agg',
33+
'price_1_min_agg_future', 'price_15_min_agg_future',
34+
'candle_1_min', 'candle_5_min', 'candle_15_min',
35+
'candle_1_min_future', 'candle_5_min_future', 'candle_15_min_future',
36+
'twap_1_min_agg', 'twap_5_min_agg', 'twap_15_min_agg',
37+
'twap_1_min_agg_future', 'twap_5_min_agg_future', 'twap_15_min_agg_future',
38+
39+
-- 1-2h aggregates
40+
'price_1_h_agg', 'price_2_h_agg',
41+
'price_1_h_agg_future', 'price_2_h_agg_future',
42+
'candle_1_h', 'candle_1_h_future',
43+
'twap_1_h_agg', 'twap_2_h_agg',
44+
'twap_1_h_agg_future', 'twap_2_h_agg_future',
45+
46+
-- Daily aggregates
47+
'price_1_day_agg', 'price_1_day_agg_future',
48+
'candle_1_day', 'candle_1_day_future',
49+
'twap_1_day_agg', 'twap_1_day_agg_future',
50+
51+
-- Weekly aggregates
52+
'price_1_week_agg', 'price_1_week_agg_future'
53+
]))
54+
LOOP
55+
-- Check if view exists
56+
IF NOT EXISTS (SELECT 1 FROM pg_matviews WHERE matviewname = view_name) THEN
57+
RAISE NOTICE 'View % does not exist, skipping...', view_name;
58+
CONTINUE;
59+
END IF;
60+
61+
-- Set compression interval based on view name pattern
62+
compress_after :=
63+
CASE
64+
WHEN view_name LIKE '%100_ms%' OR view_name LIKE '%_s_%' THEN INTERVAL '1 hour'
65+
WHEN view_name LIKE '%min%' THEN INTERVAL '6 hours'
66+
WHEN view_name LIKE '%_h_%' OR view_name LIKE '%_2_h%' THEN INTERVAL '1 day'
67+
WHEN view_name LIKE '%day%' THEN INTERVAL '7 days'
68+
WHEN view_name LIKE '%week%' THEN INTERVAL '30 days'
69+
END;
70+
71+
BEGIN
72+
-- Enable columnstore and set segmentby for each view
73+
EXECUTE format('ALTER MATERIALIZED VIEW %I SET (timescaledb.enable_columnstore = true, timescaledb.segmentby = ''pair_id'')', view_name);
74+
-- Add compression policy
75+
EXECUTE format('CALL add_columnstore_policy(%L, after => $1, if_not_exists => true)', view_name) USING compress_after;
76+
EXCEPTION
77+
WHEN OTHERS THEN
78+
RAISE WARNING 'Failed to add compression policy for view %: %', view_name, SQLERRM;
79+
END;
80+
END LOOP;
81+
END;
82+
$$ LANGUAGE plpgsql;
83+
84+
-- Add compression policies to all continuous aggregates
85+
SELECT add_compression_to_continuous_aggregates();

0 commit comments

Comments
 (0)