From b3439dcbe497de95e2618770a683cf9dcf54f6cc Mon Sep 17 00:00:00 2001 From: river Date: Mon, 9 Sep 2024 16:25:07 +0800 Subject: [PATCH] add staked daily jobs --- ...ure_holding_balance_staked_fbtc_detail.sql | 20 +++++++++ ...ture_holding_balance_staked_fbtc_detail.py | 17 +++++++ ...ture_holding_balance_staked_fbtc_detail.py | 18 ++++++++ ...riod_feature_staked_fbtc_detail_records.py | 20 +++++++++ ...ure_holding_balance_staked_fbtc_detail.sql | 45 +++++++++++++++++++ ...iod_feature_staked_fbtc_detail_records.sql | 28 ++++++++++++ 6 files changed, 148 insertions(+) create mode 100644 indexer/aggr_jobs/disorder_jobs/daily_feature_holding_balance_staked_fbtc_detail.sql create mode 100644 indexer/aggr_jobs/disorder_jobs/models/daily_feature_holding_balance_staked_fbtc_detail.py create mode 100644 indexer/aggr_jobs/order_jobs/models/period_feature_holding_balance_staked_fbtc_detail.py create mode 100644 indexer/aggr_jobs/order_jobs/models/period_feature_staked_fbtc_detail_records.py create mode 100644 indexer/aggr_jobs/order_jobs/period_feature_holding_balance_staked_fbtc_detail.sql create mode 100644 indexer/aggr_jobs/order_jobs/period_feature_staked_fbtc_detail_records.sql diff --git a/indexer/aggr_jobs/disorder_jobs/daily_feature_holding_balance_staked_fbtc_detail.sql b/indexer/aggr_jobs/disorder_jobs/daily_feature_holding_balance_staked_fbtc_detail.sql new file mode 100644 index 00000000..c4c03737 --- /dev/null +++ b/indexer/aggr_jobs/disorder_jobs/daily_feature_holding_balance_staked_fbtc_detail.sql @@ -0,0 +1,20 @@ +delete +from daily_feature_holding_balance_staked_fbtc_detail +where block_date >= '{start_date}' + and block_date < '{end_date}'; +insert into public.daily_feature_holding_balance_staked_fbtc_detail (block_date, wallet_address, protocol_id, + contract_address, balance) +select TO_TIMESTAMP(block_timestamp)::DATE as block_date, + wallet_address, + protocol_id, + contract_address, + amount +from (select *, + row_number() + over (partition by contract_address, protocol_id, wallet_address order by block_timestamp desc) rn + from feature_staked_fbtc_detail_records + where TO_TIMESTAMP(block_timestamp) >= '{start_date}' + and TO_TIMESTAMP(block_timestamp) < '{end_date}') t +where rn = 1; + + diff --git a/indexer/aggr_jobs/disorder_jobs/models/daily_feature_holding_balance_staked_fbtc_detail.py b/indexer/aggr_jobs/disorder_jobs/models/daily_feature_holding_balance_staked_fbtc_detail.py new file mode 100644 index 00000000..6cd37d3e --- /dev/null +++ b/indexer/aggr_jobs/disorder_jobs/models/daily_feature_holding_balance_staked_fbtc_detail.py @@ -0,0 +1,17 @@ +from sqlalchemy import DATE, TIMESTAMP, Column, Index, func +from sqlalchemy.dialects.postgresql import BYTEA, NUMERIC, VARCHAR + +from common.models import HemeraModel + + +class DailyFeatureHoldingBalanceStakedFbtcDetail(HemeraModel): + __tablename__ = "daily_feature_holding_balance_staked_fbtc_detail" + + block_date = Column(DATE, primary_key=True, nullable=False) + wallet_address = Column(BYTEA, primary_key=True) + protocol_id = Column(VARCHAR, primary_key=True) + contract_address = Column(BYTEA, primary_key=True) + + balance = Column(NUMERIC(100, 18)) + + create_time = Column(TIMESTAMP, server_default=func.now()) diff --git a/indexer/aggr_jobs/order_jobs/models/period_feature_holding_balance_staked_fbtc_detail.py b/indexer/aggr_jobs/order_jobs/models/period_feature_holding_balance_staked_fbtc_detail.py new file mode 100644 index 00000000..8a6d99a7 --- /dev/null +++ b/indexer/aggr_jobs/order_jobs/models/period_feature_holding_balance_staked_fbtc_detail.py @@ -0,0 +1,18 @@ +from flask_sqlalchemy import SQLAlchemy +from sqlalchemy import DATE, TIMESTAMP, Column, Index, func +from sqlalchemy.dialects.postgresql import BYTEA, NUMERIC, VARCHAR + +from common.models import HemeraModel, general_converter + + +class PeriodFeatureHoldingBalanceStakedFbtcDetail(HemeraModel): + __tablename__ = "period_feature_holding_balance_staked_fbtc_detail" + + period_date = Column(DATE, primary_key=True, nullable=False) + wallet_address = Column(BYTEA, primary_key=True) + protocol_id = Column(VARCHAR, primary_key=True) + contract_address = Column(BYTEA, primary_key=True) + + balance = Column(NUMERIC(100, 18)) + + create_time = Column(TIMESTAMP, server_default=func.now()) diff --git a/indexer/aggr_jobs/order_jobs/models/period_feature_staked_fbtc_detail_records.py b/indexer/aggr_jobs/order_jobs/models/period_feature_staked_fbtc_detail_records.py new file mode 100644 index 00000000..48a30fdd --- /dev/null +++ b/indexer/aggr_jobs/order_jobs/models/period_feature_staked_fbtc_detail_records.py @@ -0,0 +1,20 @@ +from sqlalchemy import DATE, TIMESTAMP, Column, Index, func +from sqlalchemy.dialects.postgresql import BYTEA, NUMERIC, VARCHAR + +from common.models import HemeraModel + + +class PeriodFeatureStakedFBTCDetailRecords(HemeraModel): + __tablename__ = "period_feature_staked_fbtc_detail_records" + + period_date = Column(DATE, primary_key=True, nullable=False) + contract_address = Column(BYTEA, primary_key=True) + wallet_address = Column(BYTEA, primary_key=True) + + amount = Column(NUMERIC(100)) + protocol_id = Column(VARCHAR) + + create_time = Column(TIMESTAMP, server_default=func.now()) + + +Index("period_feature_staked_fbtc_detail_records_wallet_period_date", PeriodFeatureStakedFBTCDetailRecords.period_date) diff --git a/indexer/aggr_jobs/order_jobs/period_feature_holding_balance_staked_fbtc_detail.sql b/indexer/aggr_jobs/order_jobs/period_feature_holding_balance_staked_fbtc_detail.sql new file mode 100644 index 00000000..da04e66e --- /dev/null +++ b/indexer/aggr_jobs/order_jobs/period_feature_holding_balance_staked_fbtc_detail.sql @@ -0,0 +1,45 @@ +delete +from period_feature_holding_balance_staked_fbtc_detail +where period_date >= '{start_date}' + and period_date < '{end_date}'; + +insert +into period_feature_holding_balance_staked_fbtc_detail(period_date, wallet_address, protocol_id, contract_address, balance) +with sbtc_table as (select d1.*, + decode(substring(token_address, 3), 'hex') as token_address, + case when d2.protocol_id is not null then True else FALSE end as flag + from period_feature_staked_fbtc_detail_records d1 + left join feature_staked_fbtc_lp_config d2 on d1.protocol_id = d2.protocol_id + and d1.contract_address = decode(substring(d2.contract_address, 3), 'hex') + where period_date = '{start_date}'), + + period_address_token_balance_table as (select * + from period_address_token_balances), + + + sbtc_balance_address_balance as (select d1.period_date, + d1.wallet_address, + d1.protocol_id, + d1.contract_address, + d1.amount as fbtc_balance, + d1.flag, + d2.token_address, + d2.balance as btc_balance + from sbtc_table d1 + left join period_address_token_balance_table d2 + on d1.wallet_address = d2.address + and d1.token_address = d2.token_address) + +select date('{start_date}'), + d1.wallet_address, + d1.protocol_id, + d1.contract_address, + greatest(0, case + when not flag then d1.fbtc_balance / pow(10, d2.decimals) + else LEAST(d1.fbtc_balance / pow(10, d2.decimals), d1.btc_balance / pow(10, d3.decimals)) end) + as balance + +from sbtc_balance_address_balance d1 + left join tokens d2 on d2.address = '\xC96DE26018A54D51C097160568752C4E3BD6C364' + left join tokens d3 on d1.token_address = d3.address +; \ No newline at end of file diff --git a/indexer/aggr_jobs/order_jobs/period_feature_staked_fbtc_detail_records.sql b/indexer/aggr_jobs/order_jobs/period_feature_staked_fbtc_detail_records.sql new file mode 100644 index 00000000..e2f295e8 --- /dev/null +++ b/indexer/aggr_jobs/order_jobs/period_feature_staked_fbtc_detail_records.sql @@ -0,0 +1,28 @@ +delete +from period_feature_staked_fbtc_detail_records +where period_date >= '{start_date}' + and period_date < '{end_date}'; + +with today_table as (select * + from daily_feature_holding_balance_staked_fbtc_detail + where block_date = '{start_date}'), + yesterday_table as (select * + from period_feature_staked_fbtc_detail_records + where period_date = '{start_date_previous}') + +insert +into period_feature_staked_fbtc_detail_records(period_date, wallet_address, protocol_id, + contract_address, amount) +select date('{start_date}') + AS period_date, + COALESCE(s1.wallet_address, s2.wallet_address) AS wallet_address, + COALESCE(s1.protocol_id, s2.protocol_id) AS protocol_id, + COALESCE(s1.contract_address, s2.contract_address) AS contract_address, + COALESCE(s1.balance, s2.amount, 0) AS amount + +from today_table s1 + full join + yesterday_table s2 + on s1.contract_address = s2.contract_address and s1.wallet_address = s2.wallet_address + and s1.protocol_id = s2.protocol_id +; \ No newline at end of file