From 1c5c97c40c39a599fe540b0a2e0fdaa1255c9feb Mon Sep 17 00:00:00 2001 From: Sean McGary Date: Thu, 24 Oct 2024 16:13:47 -0500 Subject: [PATCH] Setup gold table generation --- internal/config/config.go | 8 + .../202409101540_rewardSubmissions/up.go | 2 +- .../202410241239_combinedRewards/up.go | 2 +- .../migrations/202410241539_goldTables/up.go | 220 ++++++++++++++++++ internal/storage/storage.go | 9 + pkg/rewards/1_goldActiveRewards.go | 175 +++++--------- pkg/rewards/2_goldStakerRewardAmounts.go | 191 ++++++--------- pkg/rewards/3_goldOperatorRewardAmounts.go | 72 ++---- pkg/rewards/4_goldRewardsForAll.go | 94 ++------ pkg/rewards/5_goldRfaeStakers.go | 120 ++++------ pkg/rewards/6_goldRfaeOperators.go | 72 ++---- pkg/rewards/7_goldStaging.go | 30 +-- pkg/rewards/8_goldFinal.go | 12 +- pkg/rewards/rewards.go | 26 --- pkg/rewards/rewards_test.go | 12 +- 15 files changed, 498 insertions(+), 547 deletions(-) create mode 100644 internal/postgres/migrations/202410241539_goldTables/up.go diff --git a/internal/config/config.go b/internal/config/config.go index 99e5ea05..cfdd5e3f 100644 --- a/internal/config/config.go +++ b/internal/config/config.go @@ -15,6 +15,10 @@ type Environment int type Chain string +func (c Chain) String() string { + return string(c) +} + type ForkName string const ( @@ -24,6 +28,7 @@ const ( Fork_Nile ForkName = "nile" Fork_Amazon ForkName = "amazon" + Fork_Panama ForkName = "panama" ENV_PREFIX = "SIDECAR" ) @@ -235,16 +240,19 @@ func (c *Config) GetForkDates() (ForkMap, error) { return ForkMap{ Fork_Amazon: "1970-01-01", // Amazon hard fork was never on preprod as we backfilled Fork_Nile: "2024-08-14", // Last calculation end timestamp was 8-13: https://holesky.etherscan.io/tx/0xb5a6855e88c79312b7c0e1c9f59ae9890b97f157ea27e69e4f0fadada4712b64#eventlog + Fork_Panama: "2024-10-01", }, nil case Chain_Holesky: return ForkMap{ Fork_Amazon: "1970-01-01", // Amazon hard fork was never on testnet as we backfilled Fork_Nile: "2024-08-13", // Last calculation end timestamp was 8-12: https://holesky.etherscan.io/tx/0x5fc81b5ed2a78b017ef313c181d8627737a97fef87eee85acedbe39fc8708c56#eventlog + Fork_Panama: "2024-10-01", }, nil case Chain_Mainnet: return ForkMap{ Fork_Amazon: "2024-08-02", // Last calculation end timestamp was 8-01: https://etherscan.io/tx/0x2aff6f7b0132092c05c8f6f41a5e5eeeb208aa0d95ebcc9022d7823e343dd012#eventlog Fork_Nile: "2024-08-12", // Last calculation end timestamp was 8-11: https://etherscan.io/tx/0x922d29d93c02d189fc2332041f01a80e0007cd7a625a5663ef9d30082f7ef66f#eventlog + Fork_Panama: "2024-10-01", }, nil } return nil, errors.New("unsupported chain") diff --git a/internal/postgres/migrations/202409101540_rewardSubmissions/up.go b/internal/postgres/migrations/202409101540_rewardSubmissions/up.go index 0b58bc98..45c9b212 100644 --- a/internal/postgres/migrations/202409101540_rewardSubmissions/up.go +++ b/internal/postgres/migrations/202409101540_rewardSubmissions/up.go @@ -17,7 +17,7 @@ func (m *Migration) Up(db *sql.DB, grm *gorm.DB) error { amount numeric not null, strategy varchar not null, strategy_index integer not null, - multiplier numeric not null, + multiplier numeric(78) not null, start_timestamp timestamp with time zone not null, end_timestamp timestamp with time zone not null, duration bigint not null, diff --git a/internal/postgres/migrations/202410241239_combinedRewards/up.go b/internal/postgres/migrations/202410241239_combinedRewards/up.go index f48ad8ae..d6191f40 100644 --- a/internal/postgres/migrations/202410241239_combinedRewards/up.go +++ b/internal/postgres/migrations/202410241239_combinedRewards/up.go @@ -17,7 +17,7 @@ func (m *Migration) Up(db *sql.DB, grm *gorm.DB) error { amount numeric not null, strategy varchar not null, strategy_index integer not null, - multiplier numeric not null, + multiplier numeric(78) not null, start_timestamp timestamp with time zone not null, end_timestamp timestamp with time zone not null, duration integer, diff --git a/internal/postgres/migrations/202410241539_goldTables/up.go b/internal/postgres/migrations/202410241539_goldTables/up.go new file mode 100644 index 00000000..673d6fad --- /dev/null +++ b/internal/postgres/migrations/202410241539_goldTables/up.go @@ -0,0 +1,220 @@ +package _202410241539_goldTables + +import ( + "database/sql" + "github.com/Layr-Labs/go-sidecar/internal/config" + "github.com/Layr-Labs/go-sidecar/internal/storage" + "gorm.io/gorm" +) + +type Migration struct { +} + +var exludedAddresses = map[config.Chain][]string{ + config.Chain_Preprod: []string{}, + config.Chain_Holesky: []string{}, + config.Chain_Mainnet: []string{ + "0x3d4eec9f015c9016f5142055a965188d17bba06f", + "0x56458b6686a033476a9472e6917fca33ce2ba4fa", + "0xf1dfec3a799a25b9bf0911b03401e01d63915574", + "0xcc05239823c0873cef85c02f3ba58d0e8398e338", + "0x8440769d3b4cbb7ef5b04b127213b22dea23a82f", + "0x35563df2a9ca8f973cc9670dd0ea15ae60b3dbd3", + "0xcdb68cfc19a9808fd549b8b8506da0dbd5935ef4", + "0x49aff6e3baf509bfb6f151df159889feeb91f3a0", + "0x7ff1b597258e67520e7c570534d6c0955f696c4f", + "0x02179f4af1d7ea53841e3a2230375801ab3cc2f9", + "0xba59853cd3921550ae0773bb648543d138fc205a", + "0xca2d1d2b7cf448dbfc8888addb9008d71049561f", + "0xbc57586af1eaa69732d27a9d9901c6926eb811b7", + "0xf926ce2998b8c87e8b758ae46b5b4ad043f9a299", + "0x97c0551954040e958c81444c06c8543cdee64a73", + "0x8264312120aaba43adff803829e82986149d27ae", + "0x94c6326a478c1eca0fe09a07754eab89a547e4eb", + "0x6af265e3741817c6ad4bdad82d3d8976ac9bc3cf", + "0x26516df208cc2f71ad21e31f8725043ae08180b0", + "0xe2ff36e97afc1c0f5688d0ff76e7441acb0e68d7", + "0x64bd86ed5cbe443bdeda20ecfaab15ea66119603", + "0x2da4aa21033da104df6b58eaa24821be629756ae", + "0x0db954cf3399c6cfc8f8e1ba7b0f1cd97ccfcee4", + "0xda02bd9b9bb963dc3ad7f72b3648e380aba36448", + "0x748b6007c1f4fd09258fc0530cb099bf2d9bf4d1", + "0x774a78488b3aae1d8ffecd8852adb59fa9f4e0ff", + "0x33d2a6cfcd67cc62625921105f8bf052d97c29fd", + "0x6e3e0e5f8dc4c90a7382664e3db63a42b80eb9d7", + "0xe7d40d9a77caddd8e8b4b484ed14c42f3b8d763a", + "0x321e71e7ff8ccc9e7f1e7377b6546996bfccc313", + "0xd1192457d3e392a05031aa33e6efbda3aad45c53", + "0xbf0aaf43144eca99503860d8c5ac16e0875184f6", + "0xa2ed4478e543ce5071ab4bbfcc27bc4b68ed983a", + "0xe9215566641932c6429a66e6c4397ecb00915996", + "0xa743c746c59bcb5e5305af71462452d75403f353", + "0x7643ac4c159f6e36d1d20c3b843009fea577dbff", + "0xc562e53262633effbf0da533e56a792777a2b6c5", + "0xfade4c25ded89f5a0071dd44d4b3735e703c4b46", + "0x43667652452e0c5ea936071853f2e78b82d2d902", + "0x3750a7a3be3c3d4c0aa32282eeb3b64a4b35eb93", + "0xd09dfe5bc2b11db2f3aca6b7c977b635e9bfd2e0", + "0x0a4715759339c0f23d455432d8c2bc36abe749cf", + "0x86bc3b961fb5acda1a60a3ddd13e47b8b8bf5c4c", + "0x56aeebc8fbf95e7b8c572a74efb40ea9dc8ba78e", + "0x9de3c8c0bff9b63c2d579f97e977912b99135343", + "0x140fd7285bfc7bc5dc6e74fc93253d2ee65e9c69", + "0x6295bbc8ab28c51b5878798976d38ade1017af86", + "0x4a836a3fc5d75002abf3ab3118609b269f43f677", + }, +} + +func (m *Migration) Up(db *sql.DB, grm *gorm.DB) error { + queries := []string{ + `create table if not exists excluded_addresses ( + address varchar not null PRIMARY KEY, + network varchar not null, + description varchar, + created_at timestamp with timezone default currrent_timestamp, + updated_at timestamp with timezone, + deleted_at timestamp with timezone, + unique(address) + )`, + `create table if not exists gold_1_active_rewards ( + avs varchar not null, + snapshot date not null, + token varchar not null, + tokens_per_day double precision not null, + tokens_per_day_decimal numeric not null, + multiplier numeric(78) not null, + strategy varchar not null, + reward_hash varchar not null, + reward_type varchar not null, + reward_submission_date varchar not null + )`, + `create table if not exists gold_2_staker_reward_amounts ( + reward_hash varchar not null, + snapshot date NOT NULL, + token varchar not null, + tokens_per_day double precision not null, + tokens_per_day_decimal numeric not null, + avs varchar not null, + strategy varchar not null, + multiplier numeric(78) not null, + reward_type varchar not null, + reward_submission_date varchar NOT NULL, + operator varchar not null, + staker varchar not null, + shares numeric not null, + staker_weight numeric not null, + rn bigint not null, + total_weight numeric not null, + staker_proportion numeric not null, + total_staker_operator_payout numeric not null, + operator_tokens numeric not null, + staker_tokens numeric not null + )`, + `create table if not exists gold_3_operator_reward_amounts ( + reward_hash varchar not null, + snapshot date NOT NULL, + token varchar not null, + tokens_per_day double precision not null, + avs varchar not null, + strategy varchar not null, + multiplier numeric(78) not null, + reward_type varchar not null, + operator varchar not null, + operator_tokens numeric not null, + rn bigint NOT NULL + )`, + `create table if not exists gold_4_rewards_for_all ( + reward_hash varchar not null, + snapshot date NOT NULL, + token varchar not null, + tokens_per_day double precision not null, + avs varchar not null, + strategy varchar not null, + multiplier numeric(78) not null, + reward_type varchar not null, + staker varchar not null, + shares numeric not null, + staker_weight numeric not null, + rn bigint NOT NULL, + total_staker_weight numeric not null, + staker_proportion numeric not null, + staker_tokens numeric(38) not null + )`, + `create table if not exists gold_5_rfae_stakers ( + reward_hash varchar not null, + snapshot date NOT NULL, + token varchar not null, + tokens_per_day_decimal numeric not null, + avs varchar not null, + strategy varchar not null, + multiplier numeric(78) not null, + reward_type varchar not null, + reward_submission_date varchar NOT NULL, + operator varchar not null, + staker varchar not null, + shares numeric not null, + excluded_address varchar, + staker_weight numeric not null, + rn bigint NOT NULL, + total_weight numeric not null, + staker_proportion numeric not null, + total_staker_operator_payout numeric not null, + operator_tokens numeric not null, + staker_tokens numeric not null + )`, + `create table if not exists gold_6_rfae_operators ( + reward_hash varchar not null, + snapshot date NOT NULL, + token varchar not null, + tokens_per_day_decimal numeric not null, + avs varchar not null, + strategy varchar not null, + multiplier numeric(78) not null, + reward_type varchar not null, + operator varchar not null, + operator_tokens numeric not null, + rn bigint NOT NULL + )`, + `create table if not exists gold_7_staging ( + earner varchar not null, + snapshot date NOT NULL, + reward_hash varchar not null, + token varchar not null, + amount numeric not null + )`, + `create table if not exists gold_table ( + earner varchar not null, + snapshot date NOT NULL, + reward_hash varchar not null, + token varchar not null, + amount numeric not null + )`, + } + + for _, query := range queries { + if err := grm.Exec(query).Error; err != nil { + return err + } + } + for chain, addresses := range exludedAddresses { + rows := make([]*storage.ExcludedAddresses, 0) + for _, address := range addresses { + rows = append(rows, &storage.ExcludedAddresses{ + Address: address, + Network: chain.String(), + Description: "panama fork", + }) + } + if len(rows) == 0 { + continue + } + if err := grm.Model(&storage.ExcludedAddresses{}).Create(&rows).Error; err != nil { + return err + } + } + return nil +} + +func (m *Migration) GetName() string { + return "202410241539_goldTables" +} diff --git a/internal/storage/storage.go b/internal/storage/storage.go index ee1a9106..bddc17c0 100644 --- a/internal/storage/storage.go +++ b/internal/storage/storage.go @@ -83,6 +83,15 @@ type OperatorRestakedStrategies struct { DeletedAt time.Time } +type ExcludedAddresses struct { + Address string + Network string + Description string + CreatedAt time.Time + UpdatedAt time.Time + DeletedAt time.Time +} + // Not tables type ActiveAvsOperator struct { diff --git a/pkg/rewards/1_goldActiveRewards.go b/pkg/rewards/1_goldActiveRewards.go index de8a1c89..531c5439 100644 --- a/pkg/rewards/1_goldActiveRewards.go +++ b/pkg/rewards/1_goldActiveRewards.go @@ -7,46 +7,44 @@ import ( var _1_goldActiveRewardsQuery = ` insert into gold_1_active_rewards WITH active_rewards_modified as ( - SELECT - *, - calc_raw_tokens_per_day(amount, duration) as tokens_per_day, - DATETIME(@cutoffDate) as global_end_inclusive -- Inclusive means we DO USE this day as a snapshot - FROM combined_rewards - WHERE - end_timestamp >= DATETIME(@rewardsStart) - and start_timestamp <= DATETIME(@cutoffDate) - -- since we cant do backfills, each run will need to be incremental and use the - -- block_date as an upper bound - and block_date <= DATETIME(@cutoffDate) + SELECT *, + amount/(duration/86400) as tokens_per_day, + cast(@cutoffDate AS TIMESTAMP(6)) as global_end_inclusive -- Inclusive means we DO USE this day as a snapshot + FROM combined_rewards + WHERE end_timestamp >= DATE(@rewardsStart) and start_timestamp <= DATE(@cutoffDate) ), -- Cut each reward's start and end windows to handle the global range active_rewards_updated_end_timestamps as ( - SELECT - avs, - -- Cut the start and end windows to handle - -- A. Retroactive rewards that came recently whose start date is less than start_timestamp - -- B. Don't make any rewards past end_timestamp for this run - start_timestamp as reward_start_exclusive, - MIN(global_end_inclusive, end_timestamp) as reward_end_inclusive, - tokens_per_day, - token, - multiplier, - strategy, - reward_hash, - reward_type, - global_end_inclusive, - block_date as reward_submission_date - FROM active_rewards_modified + SELECT + avs, + /** + * Cut the start and end windows to handle + * A. Retroactive rewards that came recently whose start date is less than start_timestamp + * B. Don't make any rewards past end_timestamp for this run + */ + start_timestamp as reward_start_exclusive, + LEAST(global_end_inclusive, end_timestamp) as reward_end_inclusive, + tokens_per_day, + token, + multiplier, + strategy, + reward_hash, + reward_type, + global_end_inclusive, + block_date as reward_submission_date + FROM active_rewards_modified ), -- For each reward hash, find the latest snapshot active_rewards_updated_start_timestamps as ( SELECT ap.avs, - coalesce(MAX(DATE(g.snapshot)), DATE(ap.reward_start_exclusive)) as reward_start_exclusive, + COALESCE(MAX(g.snapshot), ap.reward_start_exclusive) as reward_start_exclusive, ap.reward_end_inclusive, ap.token, - post_nile_tokens_per_day(ap.tokens_per_day) as tokens_per_day_decimal, - pre_nile_tokens_per_day(ap.tokens_per_day) as tokens_per_day, + -- We use floor to ensure we are always underesimating total tokens per day + floor(ap.tokens_per_day) as tokens_per_day_decimal, + -- Round down to 15 sigfigs for double precision, ensuring know errouneous round up or down + ap.tokens_per_day * ((POW(10, 15) - 1)/(POW(10, 15))) as tokens_per_day, ap.multiplier, ap.strategy, ap.reward_hash, @@ -55,79 +53,45 @@ active_rewards_updated_start_timestamps as ( ap.reward_submission_date FROM active_rewards_updated_end_timestamps ap LEFT JOIN gold_table g ON g.reward_hash = ap.reward_hash - GROUP BY ap.avs, ap.reward_end_inclusive, ap.token, ap.tokens_per_day, ap.multiplier, ap.strategy, ap.reward_hash, ap.global_end_inclusive, ap.reward_start_exclusive, ap.reward_type, ap.reward_submission_date + GROUP BY ap.avs, ap.reward_end_inclusive, ap.token, ap.tokens_per_day, ap.multiplier, ap.strategy, ap.reward_hash, ap.global_end_inclusive, ap.reward_start_exclusive, ap.reward_type, ap.reward_submission_date ), -- Parse out invalid ranges active_reward_ranges AS ( SELECT * from active_rewards_updated_start_timestamps - -- Take out (reward_start_exclusive, reward_end_inclusive) windows where - -- 1. reward_start_exclusive >= reward_end_inclusive: The reward period is done or we will handle on a subsequent run + /** Take out (reward_start_exclusive, reward_end_inclusive) windows where + * 1. reward_start_exclusive >= reward_end_inclusive: The reward period is done or we will handle on a subsequent run + */ WHERE reward_start_exclusive < reward_end_inclusive ), - date_bounds as ( - select - min(reward_start_exclusive) as min_start, - max(reward_end_inclusive) as max_end - from active_reward_ranges - ), - day_series AS ( - with RECURSIVE day_series_inner AS ( - SELECT DATE(min_start) AS day - FROM date_bounds - UNION ALL - SELECT DATE(day, '+1 day') - FROM day_series_inner - WHERE day < (SELECT max_end FROM date_bounds) - ) - select * from day_series_inner - ), -- Explode out the ranges for a day per inclusive date - exploded_active_range_rewards AS ( - SELECT - arr.*, - day_series.day as day - FROM active_reward_ranges as arr - cross join day_series - where DATE(day_series.day) between DATE(reward_start_exclusive) and DATE(reward_end_inclusive) - ), - active_rewards_final AS ( - SELECT - avs, - DATE(day) as snapshot, - token, - tokens_per_day, - tokens_per_day_decimal, - multiplier, - strategy, - reward_hash, - reward_type, - reward_submission_date - FROM exploded_active_range_rewards - -- Remove snapshots on the start day - WHERE day != reward_start_exclusive - ) -select - avs, - snapshot, - token, - tokens_per_day, - tokens_per_day_decimal, - multiplier, - strategy, - reward_hash, - reward_type, - reward_submission_date -from active_rewards_final +exploded_active_range_rewards AS ( + SELECT + * + FROM active_reward_ranges + CROSS JOIN generate_series(DATE(reward_start_exclusive), DATE(reward_end_inclusive), INTERVAL '1' DAY) AS day +), +active_rewards_final AS ( + SELECT + avs, + cast(day as DATE) as snapshot, + token, + tokens_per_day, + tokens_per_day_decimal, + multiplier, + strategy, + reward_hash, + reward_type, + reward_submission_date + FROM exploded_active_range_rewards + -- Remove snapshots on the start day + WHERE day != reward_start_exclusive +) +select * from active_rewards_final +where + snapshot >= @startDate + and snapshot < @cutoffDate ` -type ResultRow struct { - Avs string - Snapshot string - Token string - TokensPerDay string - TokensPerDayDecimal string -} - // Generate1ActiveRewards generates active rewards for the gold_1_active_rewards table // // @param snapshotDate: The upper bound of when to calculate rewards to @@ -145,26 +109,3 @@ func (r *RewardsCalculator) Generate1ActiveRewards(cutoffDate string, startDate } return nil } - -func (r *RewardsCalculator) CreateGold1ActiveRewardsTable() error { - query := ` - create table if not exists gold_1_active_rewards ( - avs TEXT NOT NULL, - snapshot DATE NOT NULL, - token TEXT NOT NULL, - tokens_per_day TEXT NOT NULL, - tokens_per_day_decimal TEXT NOT NULL, - multiplier TEXT NOT NULL, - strategy TEXT NOT NULL, - reward_hash TEXT NOT NULL, - reward_type TEXT NOT NULL, - reward_submission_date DATE NOT NULL - ) - ` - res := r.grm.Exec(query) - if res.Error != nil { - r.logger.Sugar().Errorw("Failed to create gold_1_active_rewards table", "error", res.Error) - return res.Error - } - return nil -} diff --git a/pkg/rewards/2_goldStakerRewardAmounts.go b/pkg/rewards/2_goldStakerRewardAmounts.go index 8c67a5de..8ee85de0 100644 --- a/pkg/rewards/2_goldStakerRewardAmounts.go +++ b/pkg/rewards/2_goldStakerRewardAmounts.go @@ -9,151 +9,135 @@ const _2_goldStakerRewardAmountsQuery = ` insert into gold_2_staker_reward_amounts WITH reward_snapshot_operators as ( SELECT - ap.reward_hash, - ap.snapshot, - ap.token, - ap.tokens_per_day, - ap.tokens_per_day_decimal, - ap.avs, - ap.strategy, - ap.multiplier, - ap.reward_type, - ap.reward_submission_date, - oar.operator + ap.reward_hash, + ap.snapshot, + ap.token, + ap.tokens_per_day, + ap.tokens_per_day_decimal, + ap.avs, + ap.strategy, + ap.multiplier, + ap.reward_type, + ap.reward_submission_date, + oar.operator FROM gold_1_active_rewards ap JOIN operator_avs_registration_snapshots oar - ON ap.avs = oar.avs and ap.snapshot = oar.snapshot + ON ap.avs = oar.avs and ap.snapshot = oar.snapshot WHERE ap.reward_type = 'avs' ), -operator_restaked_strategies AS ( +_operator_restaked_strategies AS ( SELECT - rso.* + rso.* FROM reward_snapshot_operators rso JOIN operator_avs_strategy_snapshots oas ON - rso.operator = oas.operator - and rso.avs = oas.avs - and rso.strategy = oas.strategy - and rso.snapshot = oas.snapshot + rso.operator = oas.operator AND + rso.avs = oas.avs AND + rso.strategy = oas.strategy AND + rso.snapshot = oas.snapshot ), -- Get the stakers that were delegated to the operator for the snapshot staker_delegated_operators AS ( SELECT - ors.*, - sds.staker - FROM operator_restaked_strategies ors + ors.*, + sds.staker + FROM _operator_restaked_strategies ors JOIN staker_delegation_snapshots sds ON - ors.operator = sds.operator AND - ors.snapshot = sds.snapshot + ors.operator = sds.operator AND + ors.snapshot = sds.snapshot ), -- Get the shares for staker delegated to the operator staker_avs_strategy_shares AS ( SELECT - sdo.*, - sss.shares + sdo.*, + sss.shares FROM staker_delegated_operators sdo JOIN staker_share_snapshots sss ON - sdo.staker = sss.staker - and sdo.snapshot = sss.snapshot - and sdo.strategy = sss.strategy + sdo.staker = sss.staker AND + sdo.snapshot = sss.snapshot AND + sdo.strategy = sss.strategy -- Parse out negative shares and zero multiplier so there is no division by zero case WHERE sss.shares > 0 and sdo.multiplier != 0 ), -- Calculate the weight of a staker -staker_weight_grouped as ( - select - staker, - reward_hash, - snapshot, - sum_big(numeric_multiply(multiplier, shares)) as staker_weight - from staker_avs_strategy_shares - group by staker, reward_hash, snapshot -), staker_weights AS ( - SELECT - s.*, - swg.staker_weight - FROM staker_avs_strategy_shares s - left join staker_weight_grouped swg on ( - s.staker = swg.staker - and s.reward_hash = swg.reward_hash - and s.snapshot = swg.snapshot - ) + SELECT *, + SUM(multiplier * shares) OVER (PARTITION BY staker, reward_hash, snapshot) AS staker_weight + FROM staker_avs_strategy_shares ), -- Get distinct stakers since their weights are already calculated distinct_stakers AS ( SELECT * FROM ( - SELECT *, - -- We can use an arbitrary order here since the staker_weight is the same for each (staker, strategy, hash, snapshot) - -- We use strategy ASC for better debuggability - ROW_NUMBER() OVER (PARTITION BY reward_hash, snapshot, staker ORDER BY strategy ASC) as rn - FROM staker_weights + SELECT *, + -- We can use an arbitrary order here since the staker_weight is the same for each (staker, strategy, hash, snapshot) + -- We use strategy ASC for better debuggability + ROW_NUMBER() OVER (PARTITION BY reward_hash, snapshot, staker ORDER BY strategy ASC) as rn + FROM staker_weights ) t WHERE rn = 1 ORDER BY reward_hash, snapshot, staker ), -staker_weight_sum_groups as ( - select - reward_hash, - snapshot, - sum_big(staker_weight) as total_weight - from distinct_stakers - group by reward_hash, snapshot -), -- Calculate sum of all staker weights for each reward and snapshot staker_weight_sum AS ( - SELECT - s.*, - sws.total_weight - FROM distinct_stakers as s - join staker_weight_sum_groups as sws on (s.reward_hash = sws.reward_hash and s.snapshot = sws.snapshot) + SELECT *, + SUM(staker_weight) OVER (PARTITION BY reward_hash, snapshot) as total_weight + FROM distinct_stakers ), -- Calculate staker proportion of tokens for each reward and snapshot staker_proportion AS ( SELECT *, - calc_staker_proportion(staker_weight, total_weight) as staker_proportion + FLOOR((staker_weight / total_weight) * 1000000000000000) / 1000000000000000 AS staker_proportion FROM staker_weight_sum ), -- Calculate total tokens to the (staker, operator) pair staker_operator_total_tokens AS ( SELECT *, - CASE -- For snapshots that are before the hard fork AND submitted before the hard fork, we use the old calc method - WHEN snapshot < DATE(@amazonHardforkDate) AND reward_submission_date < DATE(@amazonHardforkDate) THEN - amazon_staker_token_rewards(staker_proportion, tokens_per_day) - WHEN snapshot < DATE(@nileHardforkDate) AND reward_submission_date < DATE(@nileHardforkDate) THEN - nile_staker_token_rewards(staker_proportion, tokens_per_day) - ELSE - staker_token_rewards(staker_proportion, tokens_per_day) - END as total_staker_operator_payout + CASE + -- For snapshots that are before the hard fork AND submitted before the hard fork, we use the old calc method + WHEN snapshot < DATE(@amazonHardforkDate) AND reward_submission_date < DATE(@amazonHardforkDate) THEN + cast(staker_proportion * tokens_per_day AS DECIMAL(38,0)) + WHEN snapshot < DATE(@nileHardforkDate) AND reward_submission_date < DATE(@nileHardforkDate) THEN + (staker_proportion * tokens_per_day)::text::decimal(38,0) + ELSE + FLOOR(staker_proportion * tokens_per_day_decimal) + END as total_staker_operator_payout FROM staker_proportion ), -operator_tokens as ( - select *, - CASE - WHEN snapshot < DATE(@amazonHardforkDate) AND reward_submission_date < DATE(@amazonHardforkDate) THEN - amazon_operator_token_rewards(total_staker_operator_payout) - WHEN snapshot < DATE(@nileHardforkDate) AND reward_submission_date < DATE(@nileHardforkDate) THEN - nile_operator_token_rewards(total_staker_operator_payout) - ELSE - post_nile_operator_tokens(total_staker_operator_payout) - END as operator_tokens - from staker_operator_total_tokens -), -- Calculate the token breakdown for each (staker, operator) pair token_breakdowns AS ( SELECT *, - subtract_big(total_staker_operator_payout, operator_tokens) as staker_tokens - FROM operator_tokens + CASE + WHEN snapshot < DATE(@amazonHardforkDate) AND reward_submission_date < DATE(@amazonHardforkDate) THEN + cast(total_staker_operator_payout * 0.10 AS DECIMAL(38,0)) + WHEN snapshot < DATE DATE(@nileHardforkDate) AND reward_submission_date < DATE(@nileHardforkDate) THEN + (total_staker_operator_payout * 0.10)::text::decimal(38,0) + ELSE + floor(total_staker_operator_payout * 0.10) + END as operator_tokens, + CASE + WHEN snapshot < DATE(@amazonHardforkDate) AND reward_submission_date < DATE(@amazonHardforkDate) THEN + total_staker_operator_payout - cast(total_staker_operator_payout * 0.10 as DECIMAL(38,0)) + WHEN snapshot < DATE(@nileHardforkDate) AND reward_submission_date < DATE(@nileHardforkDate) THEN + total_staker_operator_payout - ((total_staker_operator_payout * 0.10)::text::decimal(38,0)) + ELSE + total_staker_operator_payout - floor(total_staker_operator_payout * 0.10) + END as staker_tokens + FROM staker_operator_total_tokens ) SELECT * from token_breakdowns +where + snapshot >= @startDate + and snapshot < @cutoffDate ORDER BY reward_hash, snapshot, staker, operator ` func (rc *RewardsCalculator) GenerateGold2StakerRewardAmountsTable(startDate string, snapshotDate string, forks config.ForkMap) error { res := rc.grm.Exec(_2_goldStakerRewardAmountsQuery, + sql.Named("startDate", startDate), + sql.Named("cutoffDate", snapshotDate), sql.Named("amazonHardforkDate", forks[config.Fork_Amazon]), sql.Named("nileHardforkDate", forks[config.Fork_Nile]), ) @@ -163,36 +147,3 @@ func (rc *RewardsCalculator) GenerateGold2StakerRewardAmountsTable(startDate str } return nil } - -func (rc *RewardsCalculator) CreateGold2RewardAmountsTable() error { - query := ` - create table if not exists gold_2_staker_reward_amounts ( - reward_hash TEXT NOT NULL, - snapshot DATE NOT NULL, - token TEXT NOT NULL, - tokens_per_day TEXT NOT NULL, - tokens_per_day_decimal TEXT NOT NULL, - avs TEXT NOT NULL, - strategy TEXT NOT NULL, - multiplier TEXT NOT NULL, - reward_type TEXT NOT NULL, - reward_submission_date DATE NOT NULL, - operator TEXT NOT NULL, - staker TEXT NOT NULL, - shares TEXT NOT NULL, - staker_weight TEXT NOT NULL, - rn INTEGER NOT NULL, - total_weight TEXT NOT NULL, - staker_proportion TEXT NOT NULL, - total_staker_operator_payout TEXT NOT NULL, - operator_tokens TEXT NOT NULL, - staker_tokens TEXT NOT NULL - ) - ` - res := rc.grm.Exec(query) - if res.Error != nil { - rc.logger.Sugar().Errorw("Failed to create gold_2_staker_reward_amounts table", "error", res.Error) - return res.Error - } - return nil -} diff --git a/pkg/rewards/3_goldOperatorRewardAmounts.go b/pkg/rewards/3_goldOperatorRewardAmounts.go index f2ad77b1..ccd5f825 100644 --- a/pkg/rewards/3_goldOperatorRewardAmounts.go +++ b/pkg/rewards/3_goldOperatorRewardAmounts.go @@ -1,35 +1,22 @@ package rewards +import "database/sql" + const _3_goldOperatorRewardAmountsQuery = ` insert into gold_3_operator_reward_amounts -with operator_token_groups as ( - SELECT - operator, +WITH operator_token_sums AS ( + SELECT reward_hash, snapshot, - sum_big(operator_tokens) AS operator_tokens + token, + tokens_per_day, + avs, + strategy, + multiplier, + reward_type, + operator, + SUM(operator_tokens) OVER (PARTITION BY operator, reward_hash, snapshot) AS operator_tokens FROM gold_2_staker_reward_amounts - group by operator, reward_hash, snapshot -), -operator_token_sums AS ( - SELECT - g.reward_hash, - g.snapshot, - g.token, - g.tokens_per_day, - g.tokens_per_day_decimal, - g.avs, - g.strategy, - g.multiplier, - g.reward_type, - g.operator, - otg.operator_tokens - FROM gold_2_staker_reward_amounts as g - join operator_token_groups as otg on ( - g.operator = otg.operator - and g.reward_hash = otg.reward_hash - and g.snapshot = otg.snapshot - ) ), -- Dedupe the operator tokens across strategies for each operator, reward hash, and snapshot distinct_operators AS ( @@ -44,38 +31,19 @@ distinct_operators AS ( WHERE rn = 1 ) SELECT * FROM distinct_operators +where + snapshot >= @startDate + and snapshot < @cutoffDate ` -func (rc *RewardsCalculator) GenerateGold3OperatorRewardAmountsTable() error { - res := rc.grm.Exec(_3_goldOperatorRewardAmountsQuery) +func (rc *RewardsCalculator) GenerateGold3OperatorRewardAmountsTable(startDate string, snapshotDate string) error { + res := rc.grm.Exec(_3_goldOperatorRewardAmountsQuery, + sql.Named("startDate", startDate), + sql.Named("cutoffDate", snapshotDate), + ) if res.Error != nil { rc.logger.Sugar().Errorw("Failed to create gold_operator_reward_amounts", "error", res.Error) return res.Error } return nil } - -func (rc *RewardsCalculator) CreateGold3OperatorRewardsTable() error { - query := ` - create table if not exists gold_3_operator_reward_amounts ( - reward_hash TEXT NOT NULL, - snapshot DATE NOT NULL, - token TEXT NOT NULL, - tokens_per_day TEXT NOT NULL, - tokens_per_day_decimal TEXT NOT NULL, - avs TEXT NOT NULL, - strategy TEXT NOT NULL, - multiplier TEXT NOT NULL, - reward_type TEXT NOT NULL, - operator TEXT NOT NULL, - operator_tokens TEXT NOT NULL, - rn INTEGER NOT NULL - ) - ` - res := rc.grm.Exec(query) - if res.Error != nil { - rc.logger.Sugar().Errorw("Failed to create gold_3_operator_reward_amounts table", "error", res.Error) - return res.Error - } - return nil -} diff --git a/pkg/rewards/4_goldRewardsForAll.go b/pkg/rewards/4_goldRewardsForAll.go index 56f7e4a3..2d392644 100644 --- a/pkg/rewards/4_goldRewardsForAll.go +++ b/pkg/rewards/4_goldRewardsForAll.go @@ -1,5 +1,7 @@ package rewards +import "database/sql" + const _4_goldRewardsForAllQuery = ` insert into gold_4_rewards_for_all WITH reward_snapshot_stakers AS ( @@ -8,7 +10,6 @@ WITH reward_snapshot_stakers AS ( ap.snapshot, ap.token, ap.tokens_per_day, - ap.tokens_per_day_decimal, ap.avs, ap.strategy, ap.multiplier, @@ -18,31 +19,15 @@ WITH reward_snapshot_stakers AS ( FROM gold_1_active_rewards ap JOIN staker_share_snapshots as sss ON ap.strategy = sss.strategy and ap.snapshot = sss.snapshot - WHERE - ap.reward_type = 'all_stakers' - -- Parse out negative shares and zero multiplier so there is no division by zero case - AND big_gt(sss.shares, '0') and ap.multiplier != '0' + WHERE ap.reward_type = 'all_stakers' + -- Parse out negative shares and zero multiplier so there is no division by zero case + AND sss.shares > 0 and ap.multiplier != 0 ), -- Calculate the weight of a staker -staker_weights_grouped as ( - select - staker, - reward_hash, - snapshot, - sum_big(numeric_multiply(multiplier, shares)) as staker_weight - from reward_snapshot_stakers - group by staker, reward_hash, snapshot -), staker_weights AS ( - SELECT - rss.*, - swg.staker_weight - FROM reward_snapshot_stakers as rss - JOIN staker_weights_grouped as swg on ( - rss.staker = swg.staker - and rss.reward_hash = swg.reward_hash - and rss.snapshot = swg.snapshot - ) + SELECT *, + SUM(multiplier * shares) OVER (PARTITION BY staker, reward_hash, snapshot) AS staker_weight + FROM reward_snapshot_stakers ), -- Get distinct stakers since their weights are already calculated distinct_stakers AS ( @@ -58,75 +43,38 @@ distinct_stakers AS ( ORDER BY reward_hash, snapshot, staker ), -- Calculate sum of all staker weights -staker_weight_sum_groups as ( - SELECT - reward_hash, - snapshot, - sum_big(staker_weight) as total_staker_weight - FROM distinct_stakers - GROUP BY reward_hash, snapshot -), staker_weight_sum AS ( - SELECT - ds.*, - swsg.total_staker_weight - FROM distinct_stakers as ds - JOIN staker_weight_sum_groups as swsg on ( - ds.reward_hash = swsg.reward_hash - and ds.snapshot = swsg.snapshot - ) + SELECT *, + SUM(staker_weight) OVER (PARTITION BY reward_hash, snapshot) as total_staker_weight + FROM distinct_stakers ), -- Calculate staker token proportion staker_proportion AS ( SELECT *, - calc_staker_proportion(staker_weight, total_staker_weight) as staker_proportion + FLOOR((staker_weight / total_staker_weight) * 1000000000000000) / 1000000000000000 AS staker_proportion FROM staker_weight_sum ), -- Calculate total tokens to staker staker_tokens AS ( SELECT *, -- TODO: update to using floor when we reactivate this - nile_staker_token_rewards(staker_proportion, tokens_per_day) as staker_tokens - -- (tokens_per_day * staker_proportion)::text::decimal(38,0) as staker_tokens + (tokens_per_day * staker_proportion)::text::decimal(38,0) as staker_tokens FROM staker_proportion ) SELECT * from staker_tokens +where + snapshot >= @startDate + and snapshot < @cutoffDate ` -func (rc *RewardsCalculator) GenerateGold4RewardsForAllTable() error { - res := rc.grm.Exec(_4_goldRewardsForAllQuery) +func (rc *RewardsCalculator) GenerateGold4RewardsForAllTable(startDate string, snapshotDate string) error { + res := rc.grm.Exec(_4_goldRewardsForAllQuery, + sql.Named("startDate", startDate), + sql.Named("cutoffDate", snapshotDate), + ) if res.Error != nil { rc.logger.Sugar().Errorw("Failed to create gold_rewards_for_all", "error", res.Error) return res.Error } return nil } - -func (rc *RewardsCalculator) CreateGold4RewardsForAllTable() error { - query := ` - create table if not exists gold_4_rewards_for_all ( - reward_hash TEXT NOT NULL, - snapshot DATE NOT NULL, - token TEXT NOT NULL, - tokens_per_day TEXT NOT NULL, - tokens_per_day_decimal TEXT NOT NULL, - avs TEXT NOT NULL, - strategy TEXT NOT NULL, - multiplier TEXT NOT NULL, - reward_type TEXT NOT NULL, - staker TEXT NOT NULL, - shares TEXT NOT NULL, - staker_weight TEXT NOT NULL, - rn INTEGER NOT NULL, - total_staker_weight TEXT NOT NULL, - staker_proportion TEXT NOT NULL, - staker_tokens TEXT NOT NULL - ) - ` - res := rc.grm.Exec(query) - if res.Error != nil { - rc.logger.Sugar().Errorw("Failed to create gold_4_rewards_for_all table", "error", res.Error) - return res.Error - } - return nil -} diff --git a/pkg/rewards/5_goldRfaeStakers.go b/pkg/rewards/5_goldRfaeStakers.go index 417d7bb9..f777baec 100644 --- a/pkg/rewards/5_goldRfaeStakers.go +++ b/pkg/rewards/5_goldRfaeStakers.go @@ -1,6 +1,9 @@ package rewards -import "github.com/Layr-Labs/go-sidecar/internal/config" +import ( + "database/sql" + "github.com/Layr-Labs/go-sidecar/internal/config" +) const _5_goldRfaeStakersQuery = ` insert into gold_5_rfae_stakers @@ -36,8 +39,8 @@ staker_delegated_operators AS ( FROM reward_snapshot_operators rso JOIN staker_delegation_snapshots sds ON - rso.operator = sds.operator - and rso.snapshot = sds.snapshot + rso.operator = sds.operator AND + rso.snapshot = sds.snapshot ), -- Get the shares of each strategy the staker has delegated to the operator staker_strategy_shares AS ( @@ -47,31 +50,29 @@ staker_strategy_shares AS ( FROM staker_delegated_operators sdo JOIN staker_share_snapshots sss ON - sdo.staker = sss.staker - and sdo.snapshot = sss.snapshot - and sdo.strategy = sss.strategy + sdo.staker = sss.staker AND + sdo.snapshot = sss.snapshot AND + sdo.strategy = sss.strategy -- Parse out negative shares and zero multiplier so there is no division by zero case - WHERE big_gt(sss.shares, '0') and sdo.multiplier != '0' + WHERE sss.shares > 0 and sdo.multiplier != 0 ), --- Calculate the weight of a staker -staker_weights_grouped as ( - SELECT - staker, - reward_hash, - snapshot, - sum_big(numeric_multiply(multiplier, shares)) as staker_weight - from staker_strategy_shares +addresses_to_exclude AS ( + select address as excluded_address from excluded_addresses where network = @network ), +-- Parse out the stakers who are addresses +parsed_out_excluded_addresses AS ( + SELECT * from staker_strategy_shares sss + LEFT JOIN addresses_to_exclude ate ON sss.staker = ate.excluded_address + WHERE + -- The end result here is that null excluded addresses are not selected UNLESS after the cutoff date + ate.excluded_address IS NULL -- Earner is not in the exclusion list + OR sss.snapshot >= DATE(@panamaForkDate) -- Or snapshot is on or after the cutoff date +), +-- Calculate the weight of a staker staker_weights AS ( - SELECT - sss.*, - swg.staker_weight - FROM staker_strategy_shares as sss - join staker_weights_grouped as swg on ( - sss.staker = swg.staker - and sss.reward_hash = swg.reward_hash - and sss.snapshot = swg.snapshot - ) + SELECT *, + SUM(multiplier * shares) OVER (PARTITION BY staker, reward_hash, snapshot) AS staker_weight + FROM parsed_out_excluded_addresses ), -- Get distinct stakers since their weights are already calculated distinct_stakers AS ( @@ -87,84 +88,47 @@ distinct_stakers AS ( ORDER BY reward_hash, snapshot, staker ), -- Calculate sum of all staker weights for each reward and snapshot -staker_weight_sum_groups as ( - SELECT - reward_hash, - snapshot, - sum_big(staker_weight) as total_weight - FROM distinct_stakers - GROUP BY reward_hash, snapshot -), staker_weight_sum AS ( - SELECT - ds.*, - swsg.total_weight - FROM distinct_stakers as ds - JOIN staker_weight_sum_groups as swsg on ( - ds.reward_hash = swsg.reward_hash - and ds.snapshot = swsg.snapshot - ) + SELECT *, + SUM(staker_weight) OVER (PARTITION BY reward_hash, snapshot) as total_weight + FROM distinct_stakers ), -- Calculate staker proportion of tokens for each reward and snapshot staker_proportion AS ( SELECT *, - calc_staker_proportion(staker_weight, total_weight) as staker_proportion + FLOOR((staker_weight / total_weight) * 1000000000000000) / 1000000000000000 AS staker_proportion FROM staker_weight_sum ), -- Calculate total tokens to the (staker, operator) pair staker_operator_total_tokens AS ( SELECT *, - staker_token_rewards(staker_proportion, tokens_per_day_decimal) as total_staker_operator_payout + FLOOR(staker_proportion * tokens_per_day_decimal) as total_staker_operator_payout FROM staker_proportion ), -- Calculate the token breakdown for each (staker, operator) pair token_breakdowns AS ( SELECT *, - post_nile_operator_tokens(total_staker_operator_payout) as operator_tokens, - subtract_big(total_staker_operator_payout, post_nile_operator_tokens(total_staker_operator_payout)) as staker_tokens + floor(total_staker_operator_payout * 0.10) as operator_tokens, + total_staker_operator_payout - floor(total_staker_operator_payout * 0.10) as staker_tokens FROM staker_operator_total_tokens ) SELECT * from token_breakdowns +where + snapshot >= @startDate + and snapshot < @cutoffDate ORDER BY reward_hash, snapshot, staker, operator ` -func (rc *RewardsCalculator) GenerateGold5RfaeStakersTable(forks config.ForkMap) error { - res := rc.grm.Exec(_5_goldRfaeStakersQuery) +func (rc *RewardsCalculator) GenerateGold5RfaeStakersTable(startDate string, snapshotDate string, forks config.ForkMap) error { + res := rc.grm.Exec(_5_goldRfaeStakersQuery, + sql.Named("panamaForkDate", forks[config.Fork_Panama]), + sql.Named("startDate", startDate), + sql.Named("cutoffDate", snapshotDate), + sql.Named("network", rc.globalConfig.Chain.String()), + ) if res.Error != nil { rc.logger.Sugar().Errorw("Failed to generate gold_rfae_stakers", "error", res.Error) return res.Error } return nil } - -func (rc *RewardsCalculator) CreateGold5RfaeStakersTable() error { - query := ` - create table if not exists gold_5_rfae_stakers ( - reward_hash TEXT NOT NULL, - snapshot DATE NOT NULL, - token TEXT NOT NULL, - tokens_per_day TEXT NOT NULL, - avs TEXT NOT NULL, - strategy TEXT NOT NULL, - multiplier TEXT NOT NULL, - reward_type TEXT NOT NULL, - reward_submission_date DATE NOT NULL, - operator TEXT NOT NULL, - staker TEXT NOT NULL, - shares TEXT NOT NULL, - staker_weight TEXT NOT NULL, - rn INTEGER NOT NULL, - total_weight TEXT NOT NULL, - staker_proportion TEXT NOT NULL, - total_staker_operator_payout TEXT NOT NULL, - operator_tokens TEXT NOT NULL, - staker_tokens TEXT NOT NULL - ) - ` - res := rc.grm.Exec(query) - if res.Error != nil { - rc.logger.Sugar().Errorw("Failed to create gold_5_rfae_stakers table", "error", res.Error) - return res.Error - } - return nil -} diff --git a/pkg/rewards/6_goldRfaeOperators.go b/pkg/rewards/6_goldRfaeOperators.go index 9022e15e..6c8cff62 100644 --- a/pkg/rewards/6_goldRfaeOperators.go +++ b/pkg/rewards/6_goldRfaeOperators.go @@ -1,33 +1,22 @@ package rewards +import "database/sql" + const _6_goldRfaeOperatorsQuery = ` insert into gold_6_rfae_operators -with operator_token_sums_grouped as ( - select - operator, - reward_hash, - snapshot, - sum_big(operator_tokens) AS operator_tokens - from gold_5_rfae_stakers - group by operator, reward_hash, snapshot -), -operator_token_sums AS ( +WITH operator_token_sums AS ( SELECT - g.reward_hash, - g.snapshot, - g.token, - g.avs, - g.strategy, - g.multiplier, - g.reward_type, - g.operator, - otg.operator_tokens - FROM gold_5_rfae_stakers as g - join operator_token_sums_grouped as otg on ( - g.operator = otg.operator - and g.reward_hash = otg.reward_hash - and g.snapshot = otg.snapshot - ) + reward_hash, + snapshot, + token, + tokens_per_day_decimal, + avs, + strategy, + multiplier, + reward_type, + operator, + SUM(operator_tokens) OVER (PARTITION BY operator, reward_hash, snapshot) AS operator_tokens + FROM gold_5_rfae_stakers ), -- Dedupe the operator tokens across strategies for each operator, reward hash, and snapshot distinct_operators AS ( @@ -42,36 +31,19 @@ distinct_operators AS ( WHERE rn = 1 ) SELECT * FROM distinct_operators +where + snapshot >= @startDate + and snapshot < @cutoffDate ` -func (rc *RewardsCalculator) GenerateGold6RfaeOperatorsTable() error { - res := rc.grm.Exec(_6_goldRfaeOperatorsQuery) +func (rc *RewardsCalculator) GenerateGold6RfaeOperatorsTable(startDate string, snapshotDate string) error { + res := rc.grm.Exec(_6_goldRfaeOperatorsQuery, + sql.Named("startDate", startDate), + sql.Named("cutoffDate", snapshotDate), + ) if res.Error != nil { rc.logger.Sugar().Errorw("Failed to create gold_rfae_operators", "error", res.Error) return res.Error } return nil } - -func (rc *RewardsCalculator) CreateGold6RfaeOperatorsTable() error { - query := ` - create table if not exists gold_6_rfae_operators ( - reward_hash TEXT NOT NULL, - snapshot DATE NOT NULL, - token TEXT NOT NULL, - avs TEXT NOT NULL, - strategy TEXT NOT NULL, - multiplier TEXT NOT NULL, - reward_type TEXT NOT NULL, - operator TEXT NOT NULL, - operator_tokens TEXT NOT NULL, - rn INTEGER NOT NULL - ) - ` - res := rc.grm.Exec(query) - if res.Error != nil { - rc.logger.Sugar().Errorw("Failed to create gold_6_rfae_operators", "error", res.Error) - return res.Error - } - return nil -} diff --git a/pkg/rewards/7_goldStaging.go b/pkg/rewards/7_goldStaging.go index 7c92b7af..69c6a15c 100644 --- a/pkg/rewards/7_goldStaging.go +++ b/pkg/rewards/7_goldStaging.go @@ -69,7 +69,7 @@ deduped_earners AS ( snapshot, reward_hash, token, - sum_big(amount) as amount + SUM(amount) as amount FROM combined_rewards GROUP BY earner, @@ -79,10 +79,16 @@ deduped_earners AS ( ) SELECT * FROM deduped_earners +where + snapshot >= @startDate + and snapshot < @cutoffDate ` -func (rc *RewardsCalculator) GenerateGold7StagingTable() error { - res := rc.grm.Exec(_7_goldStagingQuery) +func (rc *RewardsCalculator) GenerateGold7StagingTable(startDate string, snapshotDate string) error { + res := rc.grm.Exec(_7_goldStagingQuery, + sql.Named("startDate", startDate), + sql.Named("cutoffDate", snapshotDate), + ) if res.Error != nil { rc.logger.Sugar().Errorw("Failed to create gold_staging", "error", res.Error) return res.Error @@ -90,24 +96,6 @@ func (rc *RewardsCalculator) GenerateGold7StagingTable() error { return nil } -func (rc *RewardsCalculator) CreateGold7StagingTable() error { - query := ` - create table if not exists gold_7_staging ( - earner TEXT NOT NULL, - snapshot DATE NOT NULL, - reward_hash TEXT NOT NULL, - token TEXT NOT NULL, - amount TEXT NOT NULL - ) - ` - res := rc.grm.Exec(query) - if res.Error != nil { - rc.logger.Sugar().Errorw("Failed to create gold_7_staging", "error", res.Error) - return res.Error - } - return nil -} - type GoldStagingRow struct { Earner string Snapshot string diff --git a/pkg/rewards/8_goldFinal.go b/pkg/rewards/8_goldFinal.go index cc24d91b..3db806c8 100644 --- a/pkg/rewards/8_goldFinal.go +++ b/pkg/rewards/8_goldFinal.go @@ -1,5 +1,7 @@ package rewards +import "database/sql" + const _8_goldFinalQuery = ` insert into gold_table SELECT @@ -9,10 +11,16 @@ SELECT token, amount FROM gold_7_staging +where + snapshot >= @startDate + and snapshot < @cutoffDate ` -func (rc *RewardsCalculator) GenerateGold8FinalTable(startDate string) error { - res := rc.grm.Exec(_8_goldFinalQuery) +func (rc *RewardsCalculator) GenerateGold8FinalTable(startDate string, snapshotDate string) error { + res := rc.grm.Exec(_8_goldFinalQuery, + sql.Named("startDate", startDate), + sql.Named("cutoffDate", snapshotDate), + ) if res.Error != nil { rc.logger.Sugar().Errorw("Failed to create gold_final", "error", res.Error) return res.Error diff --git a/pkg/rewards/rewards.go b/pkg/rewards/rewards.go index 45b10f46..00ec2ebb 100644 --- a/pkg/rewards/rewards.go +++ b/pkg/rewards/rewards.go @@ -27,10 +27,6 @@ func NewRewardsCalculator( globalConfig: cfg, } - if err := rc.initializeRewardsSchema(); err != nil { - l.Sugar().Errorw("Failed to initialize rewards schema", zap.Error(err)) - return nil, err - } return rc, nil } @@ -98,28 +94,6 @@ func (rc *RewardsCalculator) getMostRecentDistributionRoot() (*submittedDistribu return distributionRoot, nil } -func (rc *RewardsCalculator) initializeRewardsSchema() error { - funcs := []func() error{ - - // Gold tables - rc.CreateGold1ActiveRewardsTable, - rc.CreateGold2RewardAmountsTable, - rc.CreateGold3OperatorRewardsTable, - rc.CreateGold4RewardsForAllTable, - rc.CreateGold5RfaeStakersTable, - rc.CreateGold6RfaeOperatorsTable, - rc.CreateGold7StagingTable, - rc.Create8GoldTable, - } - for _, f := range funcs { - err := f() - if err != nil { - return err - } - } - return nil -} - func (rc *RewardsCalculator) generateSnapshotData(startDate string, snapshotDate string) error { var err error diff --git a/pkg/rewards/rewards_test.go b/pkg/rewards/rewards_test.go index 8cd57be6..45f9df5c 100644 --- a/pkg/rewards/rewards_test.go +++ b/pkg/rewards/rewards_test.go @@ -255,7 +255,7 @@ func Test_Rewards(t *testing.T) { testStart = time.Now() fmt.Printf("Running gold_3_operator_reward_amounts\n") - err = rc.GenerateGold3OperatorRewardAmountsTable() + err = rc.GenerateGold3OperatorRewardAmountsTable(startDate, snapshotDate) assert.Nil(t, err) rows, err = getRowCountForTable(grm, "gold_3_operator_reward_amounts") assert.Nil(t, err) @@ -263,7 +263,7 @@ func Test_Rewards(t *testing.T) { testStart = time.Now() fmt.Printf("Running gold_4_rewards_for_all\n") - err = rc.GenerateGold4RewardsForAllTable() + err = rc.GenerateGold4RewardsForAllTable(startDate, snapshotDate) assert.Nil(t, err) rows, err = getRowCountForTable(grm, "gold_4_rewards_for_all") assert.Nil(t, err) @@ -271,7 +271,7 @@ func Test_Rewards(t *testing.T) { testStart = time.Now() fmt.Printf("Running gold_5_rfae_stakers\n") - err = rc.GenerateGold5RfaeStakersTable(forks) + err = rc.GenerateGold5RfaeStakersTable(startDate, snapshotDate, forks) assert.Nil(t, err) rows, err = getRowCountForTable(grm, "gold_5_rfae_stakers") assert.Nil(t, err) @@ -279,7 +279,7 @@ func Test_Rewards(t *testing.T) { testStart = time.Now() fmt.Printf("Running gold_6_rfae_operators\n") - err = rc.GenerateGold6RfaeOperatorsTable() + err = rc.GenerateGold6RfaeOperatorsTable(startDate, snapshotDate) assert.Nil(t, err) rows, err = getRowCountForTable(grm, "gold_6_rfae_operators") assert.Nil(t, err) @@ -287,7 +287,7 @@ func Test_Rewards(t *testing.T) { testStart = time.Now() fmt.Printf("Running gold_7_staging\n") - err = rc.GenerateGold7StagingTable() + err = rc.GenerateGold7StagingTable(startDate, snapshotDate) assert.Nil(t, err) rows, err = getRowCountForTable(grm, "gold_7_staging") assert.Nil(t, err) @@ -295,7 +295,7 @@ func Test_Rewards(t *testing.T) { testStart = time.Now() fmt.Printf("Running gold_8_final_table\n") - err = rc.GenerateGold8FinalTable(startDate) + err = rc.GenerateGold8FinalTable(startDate, snapshotDate) assert.Nil(t, err) rows, err = getRowCountForTable(grm, "gold_table") assert.Nil(t, err)