Skip to content

Commit

Permalink
wip: added masp tables
Browse files Browse the repository at this point in the history
  • Loading branch information
Fraccaman committed Jan 15, 2025
1 parent 4459f92 commit ca2d787
Show file tree
Hide file tree
Showing 3 changed files with 220 additions and 55 deletions.
8 changes: 8 additions & 0 deletions orm/migrations/2025-01-15-135342_masp/down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
-- This file should undo anything in `up.sql`
DROP TABLE IF EXISTS masp_pool;

DROP TABLE IF EXISTS masp_pool_aggregate;

DROP TYPE IF EXISTS MASP_POOL_AGGREGATE_WINDOW;

DROP TYPE IF EXISTS MASP_POOL_AGGREGATE_KIND;
163 changes: 163 additions & 0 deletions orm/migrations/2025-01-15-135342_masp/up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,163 @@
-- Your SQL goes here
CREATE TABLE masp_pool (
id SERIAL PRIMARY KEY,
token_address VARCHAR(45) NOT NULL,
timestamp TIMESTAMP NOT NULL,
raw_amount NUMERIC(78, 0) NOT NULL,
inner_tx_id VARCHAR(64) NOT NULL,
CONSTRAINT fk_inner_tx_id FOREIGN KEY(inner_tx_id) REFERENCES inner_transactions(id) ON DELETE CASCADE
);

CREATE INDEX index_masp_pool_address_timestamp ON masp_pool (token_address, timestamp DESC);

CREATE TYPE MASP_POOL_AGGREGATE_WINDOW AS ENUM (
'1',
'7',
'30',
'Inf'
);

CREATE TYPE MASP_POOL_AGGREGATE_KIND AS ENUM (
'inflows',
'outflows'
);

CREATE TABLE masp_pool_aggregate (
id SERIAL PRIMARY KEY,
token_address VARCHAR(45) NOT NULL,
time_window MASP_POOL_AGGREGATE_WINDOW NOT NULL,
kind MASP_POOL_AGGREGATE_KIND NOT NULL,
total_amount NUMERIC(78, 0) NOT NULL DEFAULT 0
);

CREATE UNIQUE INDEX index_masp_pool_aggregate_token_address_window_kind ON masp_pool_aggregate (token_address, time_window, kind);

-- if it doesn't work ask for a fix to https://chatgpt.com
CREATE OR REPLACE FUNCTION update_masp_pool_aggregate_sum()
RETURNS TRIGGER AS $$
--
-- This function is triggered before an insert into the `masp_pool` table.
-- It calculates the running sum of amounts for different time windows (1-day, 7-day, 30-day, and all-time).
-- Depending on whether the `raw_amount` is positive or negative, it updates the corresponding `inflow` or `outflow`
-- entry in the `masp_pool_aggregate` table.
--
-- The `inflow` entry is updated if `raw_amount` is positive, while the `outflow` entry is updated if `raw_amount`
-- is negative. The sum is incrementally updated for each of the windows:
-- 1-day, 7-day, 30-day, and all-time.
--
-- The trigger ensures that the `masp_pool_aggregate` table reflects the running total of both inflow and outflow
-- amounts, for each token address, over different time windows.
--
DECLARE
cutoff_1d TIMESTAMP := now() - INTERVAL '1 day';
cutoff_7d TIMESTAMP := now() - INTERVAL '7 days';
cutoff_30d TIMESTAMP := now() - INTERVAL '30 days';
BEGIN
-- Update 1-day time_window for 'inflow' or 'outflow'
IF NEW.raw_amount > 0 THEN
-- Inflow: update inflow entry
INSERT INTO masp_pool_aggregate (token_address, time_window, kind, total_amount)
VALUES (
NEW.token_address,
'1d',
'inflows',
NEW.raw_amount
)
ON CONFLICT (token_address, time_window, kind)
DO UPDATE SET total_amount = masp_pool_aggregate.total_amount + EXCLUDED.total_amount;
ELSE
-- Outflow: update outflow entry
INSERT INTO masp_pool_aggregate (token_address, time_window, kind, total_amount)
VALUES (
NEW.token_address,
'1d',
'outflows',
NEW.raw_amount
)
ON CONFLICT (token_address, time_window, kind)
DO UPDATE SET total_amount = masp_pool_aggregate.total_amount + EXCLUDED.total_amount;
END IF;

-- Update 7-day time_window for 'inflow' or 'outflow'
IF NEW.raw_amount > 0 THEN
-- Inflow: update inflow entry
INSERT INTO masp_pool_aggregate (token_address, time_window, kind, total_amount)
VALUES (
NEW.token_address,
'7d',
'inflows',
NEW.raw_amount
)
ON CONFLICT (token_address, time_window, kind)
DO UPDATE SET total_amount = masp_pool_aggregate.total_amount + EXCLUDED.total_amount;
ELSE
-- Outflow: update outflow entry
INSERT INTO masp_pool_aggregate (token_address, time_window, kind, total_amount)
VALUES (
NEW.token_address,
'7d',
'outflows',
NEW.raw_amount
)
ON CONFLICT (token_address, time_window, kind)
DO UPDATE SET total_amount = masp_pool_aggregate.total_amount + EXCLUDED.total_amount;
END IF;

-- Update 30-day time_window for 'inflow' or 'outflow'
IF NEW.raw_amount > 0 THEN
-- Inflow: update inflow entry
INSERT INTO masp_pool_aggregate (token_address, time_window, kind, total_amount)
VALUES (
NEW.token_address,
'30d',
'inflows',
NEW.raw_amount
)
ON CONFLICT (token_address, time_window, kind)
DO UPDATE SET total_amount = masp_pool_aggregate.total_amount + EXCLUDED.total_amount;
ELSE
-- Outflow: update outflow entry
INSERT INTO masp_pool_aggregate (token_address, time_window, kind, total_amount)
VALUES (
NEW.token_address,
'30d',
'outflows',
NEW.raw_amount
)
ON CONFLICT (token_address, time_window, kind)
DO UPDATE SET total_amount = masp_pool_aggregate.total_amount + EXCLUDED.total_amount;
END IF;

-- Update all-time time_window for 'inflow' or 'outflow'
IF NEW.raw_amount > 0 THEN
-- Inflow: update inflow entry
INSERT INTO masp_pool_aggregate (token_address, time_window, kind, total_amount)
VALUES (
NEW.token_address,
'Inf',
'inflows',
NEW.raw_amount
)
ON CONFLICT (token_address, time_window, kind)
DO UPDATE SET total_amount = masp_pool_aggregate.total_amount + EXCLUDED.total_amount;
ELSE
-- Outflow: update outflow entry
INSERT INTO masp_pool_aggregate (token_address, time_window, kind, total_amount)
VALUES (
NEW.token_address,
'Inf',
'outflows',
NEW.raw_amount
)
ON CONFLICT (token_address, time_window, kind)
DO UPDATE SET total_amount = masp_pool_aggregate.total_amount + EXCLUDED.total_amount;
END IF;

RETURN NEW;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER update_masp_pool_aggregate_sum_trigger
AFTER INSERT ON masp_pool
FOR EACH ROW
EXECUTE FUNCTION update_masp_pool_aggregate_sum();
104 changes: 49 additions & 55 deletions orm/src/schema.rs
Original file line number Diff line number Diff line change
@@ -1,91 +1,55 @@
// @generated automatically by Diesel CLI.

pub mod sql_types {
#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "crawler_name"))]
pub struct CrawlerName;

#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "governance_kind"))]
pub struct GovernanceKind;

#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "governance_result"))]
pub struct GovernanceResult;

#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "governance_tally_type"))]
pub struct GovernanceTallyType;

#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "history_kind"))]
pub struct HistoryKind;

#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "ibc_status"))]
pub struct IbcStatus;

#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "masp_pool_aggregate_kind"))]
pub struct MaspPoolAggregateKind;

#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "masp_pool_aggregate_window"))]
pub struct MaspPoolAggregateWindow;

#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "token_type"))]
pub struct TokenType;

#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "transaction_kind"))]
pub struct TransactionKind;

#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "transaction_result"))]
pub struct TransactionResult;

#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "validator_state"))]
pub struct ValidatorState;

#[derive(
diesel::query_builder::QueryId,
std::fmt::Debug,
diesel::sql_types::SqlType,
)]
#[derive(diesel::query_builder::QueryId, std::fmt::Debug, diesel::sql_types::SqlType)]
#[diesel(postgres_type(name = "vote_kind"))]
pub struct VoteKind;
}
Expand Down Expand Up @@ -268,6 +232,33 @@ diesel::table! {
}
}

diesel::table! {
masp_pool (id) {
id -> Int4,
#[max_length = 45]
token_address -> Varchar,
timestamp -> Timestamp,
raw_amount -> Numeric,
#[max_length = 64]
inner_tx_id -> Varchar,
}
}

diesel::table! {
use diesel::sql_types::*;
use super::sql_types::MaspPoolAggregateWindow;
use super::sql_types::MaspPoolAggregateKind;

masp_pool_aggregate (id) {
id -> Int4,
#[max_length = 45]
token_address -> Varchar,
time_window -> MaspPoolAggregateWindow,
kind -> MaspPoolAggregateKind,
total_amount -> Numeric,
}
}

diesel::table! {
pos_rewards (id) {
id -> Int4,
Expand Down Expand Up @@ -363,6 +354,7 @@ diesel::joinable!(gas_estimations -> wrapper_transactions (wrapper_id));
diesel::joinable!(governance_votes -> governance_proposals (proposal_id));
diesel::joinable!(ibc_token -> token (address));
diesel::joinable!(inner_transactions -> wrapper_transactions (wrapper_id));
diesel::joinable!(masp_pool -> inner_transactions (inner_tx_id));
diesel::joinable!(pos_rewards -> validators (validator_id));
diesel::joinable!(transaction_history -> inner_transactions (inner_tx_id));
diesel::joinable!(unbonds -> validators (validator_id));
Expand All @@ -382,6 +374,8 @@ diesel::allow_tables_to_appear_in_same_query!(
ibc_ack,
ibc_token,
inner_transactions,
masp_pool,
masp_pool_aggregate,
pos_rewards,
revealed_pk,
token,
Expand Down

0 comments on commit ca2d787

Please sign in to comment.