Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: cleanup migrations and add compression #198

Merged
merged 4 commits into from
Mar 16, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
4 changes: 2 additions & 2 deletions compose.dev.yaml
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
services:
onchain-db:
image: timescale/timescaledb-ha:pg14-latest
image: timescale/timescaledb-ha:pg17.4-ts2.18.2
restart: always
user: postgres
networks:
Expand Down Expand Up @@ -37,7 +37,7 @@ services:
retries: 5

offchain-db:
image: timescale/timescaledb-ha:pg14-latest
image: timescale/timescaledb-ha:pg17.4-ts2.18.2
restart: always
user: postgres
networks:
Expand Down
2 changes: 1 addition & 1 deletion openapi.json

Large diffs are not rendered by default.

34 changes: 32 additions & 2 deletions pragma-entities/migrations/2023-10-11-223513_create_entries/up.sql
Original file line number Diff line number Diff line change
@@ -1,13 +1,43 @@
-- Your SQL goes here
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";

-- SPOT entries

CREATE TABLE entries (
id uuid DEFAULT uuid_generate_v4(),
pair_id VARCHAR NOT NULL,
publisher TEXT NOT NULL,
timestamp TIMESTAMPTZ NOT NULL,
price NUMERIC NOT NULL,
timestamp TIMESTAMPTZ NOT NULL,
publisher TEXT NOT NULL,
publisher_signature TEXT NULLABLE,
source VARCHAR NOT NULL,
PRIMARY KEY (id, timestamp)
);

CREATE UNIQUE INDEX idx_entries_unique
ON entries(pair_id, source, timestamp DESC);
CREATE INDEX entries_pair_id_timestamp_idx ON entries (pair_id, timestamp DESC);

SELECT
create_hypertable('entries', 'timestamp');

-- FUTURE (PERP) entries

CREATE TABLE future_entries (
id uuid DEFAULT uuid_generate_v4(),
pair_id VARCHAR NOT NULL,
price NUMERIC NOT NULL,
timestamp TIMESTAMPTZ NOT NULL,
expiration_timestamp TIMESTAMPTZ NULLABLE, -- can be NULL for perp contracts
publisher TEXT NOT NULL,
publisher_signature TEXT NULLABLE,
source VARCHAR NOT NULL,
PRIMARY KEY (id, timestamp)
);

CREATE UNIQUE INDEX idx_future_entries_unique ON future_entries(pair_id, source, timestamp, expiration_timestamp);
CREATE INDEX idx_future_entries_pair_id_timestamp ON future_entries (pair_id, timestamp DESC);
CREATE INDEX idx_future_entries_pair_id_timestamp_expiration_timestamp ON future_entries (pair_id, expiration_timestamp, timestamp DESC);

SELECT
create_hypertable('future_entries', 'timestamp');

This file was deleted.

This file was deleted.

Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ CREATE TABLE publishers (
name VARCHAR NOT NULL,
master_key VARCHAR NOT NULL,
active_key VARCHAR NOT NULL,
active BOOLEAN NOT NULL,
account_address VARCHAR NOT NULL DEFAULT '',
active BOOLEAN NOT NULL DEFAULT true,
PRIMARY KEY (id)
);
Original file line number Diff line number Diff line change
@@ -1,7 +1,4 @@
-- Your SQL goes here
ALTER TABLE publishers
ADD COLUMN account_address VARCHAR NOT NULL DEFAULT '';

INSERT INTO publishers (name, master_key, active_key, active, account_address)
VALUES (
'PRAGMA',
Expand Down

This file was deleted.

This file was deleted.

This file was deleted.

This file was deleted.

This file was deleted.

This file was deleted.

Original file line number Diff line number Diff line change
@@ -1,4 +1,26 @@
-- This file should undo anything in `up.sql`

-- Drop spot price aggregates
DROP MATERIALIZED VIEW IF EXISTS price_100_ms_agg;
DROP MATERIALIZED VIEW IF EXISTS price_1_s_agg;
DROP MATERIALIZED VIEW IF EXISTS price_5_s_agg;
DROP MATERIALIZED VIEW IF EXISTS price_1_min_agg;
DROP MATERIALIZED VIEW IF EXISTS price_15_min_agg;
DROP MATERIALIZED VIEW IF EXISTS price_1_h_agg;
DROP MATERIALIZED VIEW IF EXISTS price_1_h_agg;
DROP MATERIALIZED VIEW IF EXISTS price_2_h_agg;
DROP MATERIALIZED VIEW IF EXISTS price_1_day_agg;
DROP MATERIALIZED VIEW IF EXISTS price_1_week_agg;

-- Drop future price aggregates
DROP MATERIALIZED VIEW IF EXISTS price_100_ms_agg_future;
DROP MATERIALIZED VIEW IF EXISTS price_1_s_agg_future;
DROP MATERIALIZED VIEW IF EXISTS price_5_s_agg_future;
DROP MATERIALIZED VIEW IF EXISTS price_1_min_agg_future;
DROP MATERIALIZED VIEW IF EXISTS price_15_min_agg_future;
DROP MATERIALIZED VIEW IF EXISTS price_1_h_agg_future;
DROP MATERIALIZED VIEW IF EXISTS price_2_h_agg_future;
DROP MATERIALIZED VIEW IF EXISTS price_1_day_agg_future;
DROP MATERIALIZED VIEW IF EXISTS price_1_week_agg_future;

-- Drop the function
DROP FUNCTION IF EXISTS create_continuous_aggregate;
Original file line number Diff line number Diff line change
@@ -1,49 +1,52 @@
-- Your SQL goes here
CREATE MATERIALIZED VIEW price_1_min_agg
WITH (timescaledb.continuous, timescaledb.materialized_only = true)
AS SELECT
pair_id,
time_bucket('1 min'::interval, timestamp) as bucket,
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
COUNT(DISTINCT source) as num_sources
FROM entries
GROUP BY bucket, pair_id
WITH NO DATA;
CREATE OR REPLACE FUNCTION create_continuous_aggregate(
p_name text,
p_interval interval,
p_start_offset interval,
p_table_name text
)
RETURNS void AS $$
BEGIN
EXECUTE format('
CREATE MATERIALIZED VIEW %I
WITH (timescaledb.continuous, timescaledb.materialized_only = false)
AS SELECT
pair_id,
time_bucket(%L, timestamp) as bucket,
(percentile_cont(0.5) WITHIN GROUP (ORDER BY price))::numeric(1000,0) AS median_price,
COUNT(DISTINCT source) as num_sources
FROM %I
GROUP BY bucket, pair_id
WITH NO DATA;', p_name, p_interval, p_table_name);

SELECT add_continuous_aggregate_policy('price_1_min_agg',
start_offset => NULL,
end_offset => INTERVAL '1 min',
schedule_interval => INTERVAL '1 min');
EXECUTE format('
SELECT add_continuous_aggregate_policy(%L,
start_offset => %L,
end_offset => %L,
schedule_interval => %L);', p_name, p_start_offset, '0'::interval, p_interval);
END;
$$ LANGUAGE plpgsql;

CREATE MATERIALIZED VIEW price_15_min_agg
WITH (timescaledb.continuous, timescaledb.materialized_only = true)
AS SELECT
pair_id,
time_bucket('15 min'::interval, timestamp) as bucket,
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
COUNT(DISTINCT source) as num_sources
FROM entries
GROUP BY bucket, pair_id
WITH NO DATA;
-- Spot entries aggregates
SELECT create_continuous_aggregate('price_100_ms_agg', '100 milliseconds'::interval, '300 milliseconds'::interval, 'entries');
SELECT create_continuous_aggregate('price_1_s_agg', '1 second'::interval, '3 seconds'::interval, 'entries');
SELECT create_continuous_aggregate('price_10_s_agg', '10 seconds'::interval, '30 seconds'::interval, 'entries');
SELECT create_continuous_aggregate('price_5_s_agg', '5 seconds'::interval, '15 seconds'::interval, 'entries');
SELECT create_continuous_aggregate('price_1_min_agg', '1 minute'::interval, '3 minutes'::interval, 'entries');
SELECT create_continuous_aggregate('price_15_min_agg', '15 minutes'::interval, '45 minutes'::interval, 'entries');
SELECT create_continuous_aggregate('price_1_h_agg', '1 hour'::interval, '3 hours'::interval, 'entries');
SELECT create_continuous_aggregate('price_2_h_agg', '2 hours'::interval, '6 hours'::interval, 'entries');
SELECT create_continuous_aggregate('price_1_day_agg', '1 day'::interval, '3 days'::interval, 'entries');
SELECT create_continuous_aggregate('price_1_week_agg', '1 week'::interval, '3 weeks'::interval, 'entries');

SELECT add_continuous_aggregate_policy('price_15_min_agg',
start_offset => NULL,
end_offset => INTERVAL '15 min',
schedule_interval => INTERVAL '15 min');

CREATE MATERIALIZED VIEW price_1_h_agg
WITH (timescaledb.continuous, timescaledb.materialized_only = true)
AS SELECT
pair_id,
time_bucket('1 hour'::interval, timestamp) as bucket,
approx_percentile(0.5, percentile_agg(price))::numeric AS median_price,
COUNT(DISTINCT source) as num_sources
FROM entries
GROUP BY bucket, pair_id
WITH NO DATA;

SELECT add_continuous_aggregate_policy('price_1_h_agg',
start_offset => NULL,
end_offset => INTERVAL '1 hour',
schedule_interval => INTERVAL '1 hour');
-- Future entries aggregates
SELECT create_continuous_aggregate('price_100_ms_agg_future', '100 milliseconds'::interval, '300 milliseconds'::interval, 'future_entries');
SELECT create_continuous_aggregate('price_1_s_agg_future', '1 second'::interval, '3 seconds'::interval, 'future_entries');
SELECT create_continuous_aggregate('price_10_s_agg_future', '10 seconds'::interval, '30 seconds'::interval, 'future_entries');
SELECT create_continuous_aggregate('price_5_s_agg_future', '5 seconds'::interval, '15 seconds'::interval, 'future_entries');
SELECT create_continuous_aggregate('price_1_min_agg_future', '1 minute'::interval, '3 minutes'::interval, 'future_entries');
SELECT create_continuous_aggregate('price_15_min_agg_future', '15 minutes'::interval, '45 minutes'::interval, 'future_entries');
SELECT create_continuous_aggregate('price_1_h_agg_future', '1 hour'::interval, '3 hours'::interval, 'future_entries');
SELECT create_continuous_aggregate('price_2_h_agg_future', '2 hours'::interval, '6 hours'::interval, 'future_entries');
SELECT create_continuous_aggregate('price_1_day_agg_future', '1 day'::interval, '3 days'::interval, 'future_entries');
SELECT create_continuous_aggregate('price_1_week_agg_future', '1 week'::interval, '3 weeks'::interval, 'future_entries');

This file was deleted.

This file was deleted.

Original file line number Diff line number Diff line change
@@ -1,6 +1,18 @@
-- This file should undo anything in `up.sql`
DROP MATERIALIZED VIEW IF EXISTS one_day_candle;
DROP MATERIALIZED VIEW IF EXISTS one_hour_candle;
DROP MATERIALIZED VIEW IF EXISTS fifteen_minute_candle;
DROP MATERIALIZED VIEW IF EXISTS five_minute_candle;
DROP MATERIALIZED VIEW IF EXISTS one_minute_candle;

-- Drop spot candlestick views
DROP MATERIALIZED VIEW IF EXISTS candle_1_min;
DROP MATERIALIZED VIEW IF EXISTS candle_5_min;
DROP MATERIALIZED VIEW IF EXISTS candle_15_min;
DROP MATERIALIZED VIEW IF EXISTS candle_1_h;
DROP MATERIALIZED VIEW IF EXISTS candle_1_day;

-- Drop future candlestick views
DROP MATERIALIZED VIEW IF EXISTS candle_1_min_future;
DROP MATERIALIZED VIEW IF EXISTS candle_5_min_future;
DROP MATERIALIZED VIEW IF EXISTS candle_15_min_future;
DROP MATERIALIZED VIEW IF EXISTS candle_1_h_future;
DROP MATERIALIZED VIEW IF EXISTS candle_1_day_future;

-- Drop the function
DROP FUNCTION IF EXISTS create_candlestick_view;
Loading