Skip to content

Commit

Permalink
Introduce manual price corrections table (#504)
Browse files Browse the repository at this point in the history
This PR is a simplification of PR #498 , where we skip the analytics db
and directly store the corrections in a file in this repo.

To identify problematic txs, i used this Dune query

```
select
    environment,
    auction_id,
    tx_hash,
    protocol_fee / pow(10,18) as protocol_fee_in_eth,
    network_fee / pow(10,18) as network_fee_in_eth
from
    "query_4351957(blockchain='ethereum')"
where
    network_fee / pow(10, 18) > 10
    or protocol_fee / pow(10, 18) > 10
order by
    auction_id desc
```
  • Loading branch information
harisang authored Feb 3, 2025
1 parent 88ab40e commit be8716d
Show file tree
Hide file tree
Showing 10 changed files with 197 additions and 13 deletions.
3 changes: 3 additions & 0 deletions queries/orderbook/.sqlfluff
Original file line number Diff line number Diff line change
Expand Up @@ -5,3 +5,6 @@ EPSILON_LOWER=10000000000000000
EPSILON_UPPER=12000000000000000
results=solver_rewards_script_table
env=prod
auction_prices_corrections=
blockchain=ethereum
environment=prod
85 changes: 85 additions & 0 deletions queries/orderbook/auction_prices_corrections.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,85 @@
auction_prices_corrections (blockchain, environment, auction_id, token, price) as ( --noqa: PRS
select *
from (
values
-- 0x1c8612facfffd21b56989ada5b740192c70a7f59f6fa257c02ab3cbd2382cef1, protocol fee issue
('ethereum', 'prod', 10105330::bigint, '\xad038eb671c44b853887a7e32528fab35dc5d710'::bytea, 43314929461672::numeric(78, 0)),

-- 0x4d4a1218787a5d3e87f63774d7422771537a846e9a55d3447c56f14b399ddf3c, protocol fee issue
('ethereum', 'prod', 10105327::bigint, '\x06b964d96f5dcf7eae9d7c559b09edce244d4b8e'::bytea, 124975619281188::numeric(78, 0)),

-- 0xc6b996f74c9c6df1d79806e88fb6a6f17ea11eef521644ec6fecc8fdf5d8d571, network fee issue
('ethereum', 'prod', 10105270::bigint, '\x4c5cb5d87709387f8821709f7a6664f00dcf0c93'::bytea, 3464500573709::numeric(78, 0)),

-- 0x9cf5a2a1cea3548c934b13610e83f79ee94f8a6974082b1ebebbbd03c3d1b887, network fee issue
('ethereum', 'prod', 10105162::bigint, '\xe2cfd7a01ec63875cd9da6c7c1b7025166c2fa2f'::bytea, 163508274::numeric(78, 0)),

-- 0x72e083668ae99eb9ae0b936e1e132c302b088ce8f49f36130b4b472d98d8abce, network fee issue
('ethereum', 'prod', 10105159::bigint, '\xe2cfd7a01ec63875cd9da6c7c1b7025166c2fa2f'::bytea, 163508274::numeric(78, 0)),

-- 0x15c54ff228b4ab388c2597a80d43c672b2ef659e8b2fb296e447d63281ad305f, protocol fee issue
('ethereum', 'prod', 10105158::bigint, '\x06b964d96f5dcf7eae9d7c559b09edce244d4b8e'::bytea, 124975619281188::numeric(78, 0)),

-- 0xdd94895f5c298ae61ca14c15c0e99b361d96bc3c667dd155eec1ea59bb99845d, network fee issue
('ethereum', 'prod', 10105154::bigint, '\xe2cfd7a01ec63875cd9da6c7c1b7025166c2fa2f'::bytea, 163508274::numeric(78, 0)),

-- 0xda1cbce2d955bb2f072635be29ef4f14660493b9b5d344f2e911d2f6927eb64c, network fee issue
('ethereum', 'prod', 10105150::bigint, '\xe2cfd7a01ec63875cd9da6c7c1b7025166c2fa2f'::bytea, 163508274::numeric(78, 0)),

-- 0x113173806a780ada8164edcd8accfc29196ff67909c11807e7b98933c2d058da, network fee issue
('ethereum', 'prod', 10105145::bigint, '\x66b5228cfd34d9f4d9f03188d67816286c7c0b74'::bytea, 859279431572::numeric(78, 0)),

-- 0xcd56ad32fa719a00fc44b7d0934e3316d1106142911eec0b3b41dd34f4354f96, protocol fee issue
('ethereum', 'prod', 10105124::bigint, '\x5c47902c8c80779cb99235e42c354e53f38c3b0d'::bytea, 101902651::numeric(78, 0)),

-- 0x1b1dfef2b14e6d9905acc2131817d8d9f58bcdfc425cbb370b0360e597dc0bf1, network fee issue
('ethereum', 'prod', 10105008::bigint, '\xe2cfd7a01ec63875cd9da6c7c1b7025166c2fa2f'::bytea, 163508274::numeric(78, 0)),

-- 0x48a58a8e5eb3ed4dd0c637338753ae62076a67ddf51b1c0ede701935dc08b66b, network fee issue
('ethereum', 'prod', 10104988::bigint, '\xe2cfd7a01ec63875cd9da6c7c1b7025166c2fa2f'::bytea, 163508274::numeric(78, 0)),

-- 0x8860e2b131547119566d2cd75acb5643a922fbfc68dfba1176bf608b0ce8ea01, network fee issue
('ethereum', 'prod', 10104987::bigint, '\xe2cfd7a01ec63875cd9da6c7c1b7025166c2fa2f'::bytea, 163508274::numeric(78, 0)),

-- 0xafc84eea4320e91c0e5eb7c1d1a24e03b2b764d1d9c7d6f97df42efab4a3bd62, network fee issue
('ethereum', 'prod', 10104982::bigint, '\xe2cfd7a01ec63875cd9da6c7c1b7025166c2fa2f'::bytea, 163508274::numeric(78, 0)),

-- 0x8aa4e5977d604abc9183036d21a2cdb17f66e490474cec6e6d069d0cb858d25d, protocol fee issue
('ethereum', 'prod', 10104824::bigint, '\x0943d06a5ff3b25ddc51642717680c105ad63c01'::bytea, 144858293311::numeric(78, 0)),

-- 0xa743eef8e27e85f02e75778de908be0bd5416678be2bd29bf8d984a37b4e7bd2, network fee issue
('ethereum', 'prod', 10104816::bigint, '\x777172d858dc1599914a1c4c6c9fc48c99a60990'::bytea, 37515633095045::numeric(78, 0)),

-- 0x4fc54d82ab8b1488dbe6a65cb0fe79511aa93fd0748a8a1eed3dd0979f4c8920, network fee issue
('ethereum', 'prod', 10104812::bigint, '\x777172d858dc1599914a1c4c6c9fc48c99a60990'::bytea, 37515633095045::numeric(78, 0)),

-- 0x8e1a1801f21b2f1972480aa8c3f72dc0b99228b71281d1401357c252b0485b76, network fee issue
('ethereum', 'prod', 10104810::bigint, '\x777172d858dc1599914a1c4c6c9fc48c99a60990'::bytea, 37515633095045::numeric(78, 0)),

-- 0xa8effb0d951d650353dba5409e25e4affa141d62f91d523e21247a2f4153413e, network fee issue
('ethereum', 'prod', 10104808::bigint, '\x777172d858dc1599914a1c4c6c9fc48c99a60990'::bytea, 37515633095045::numeric(78, 0)),

-- 0x04d6c08273e587f7ccca09100d8a432ecef87444e9e7a6ae17a1f2f36bedb1eb, network fee issue
('ethereum', 'prod', 10104805::bigint, '\x777172d858dc1599914a1c4c6c9fc48c99a60990'::bytea, 37515633095045::numeric(78, 0)),

-- 0x04d6c08273e587f7ccca09100d8a432ecef87444e9e7a6ae17a1f2f36bedb1eb, network fee issue
('ethereum', 'prod', 10104805::bigint, '\x9f278dc799bbc61ecb8e5fb8035cbfa29803623b'::bytea, 1274000005::numeric(78, 0)),

-- 0xbbeb89e06b30614b6364c362bae217b541e7b9c72dc4fe9d0c93622fed028f91, network fee issue
('ethereum', 'prod', 10104748::bigint, '\x4eca7761a516f8300711cbf920c0b85555261993'::bytea, 23670618::numeric(78, 0)),

-- 0x958089dd2a50f555f89f872c9fb83882d29750f78ad3096c9f535b08e030928e, network fee issue
('ethereum', 'prod', 10104733::bigint, '\xad038eb671c44b853887a7e32528fab35dc5d710'::bytea, 43314929461672::numeric(78, 0)),

-- 0xb46617d67c592518ed51d2a00292d0e86728b1ac9aa700220c0b010b19b5f96b, network fee issue
('ethereum', 'prod', 10104715::bigint, '\x1a88df1cfe15af22b3c4c783d4e6f7f9e0c1885d'::bytea, 318978711000518::numeric(78, 0)),

-- 0xd6bd149df0d16cc26b1e2581e25340bf6aa31bf218cbffd4cbb5e55e9d1dfae2, network fee issue
('ethereum', 'prod', 10104624::bigint, '\x4eca7761a516f8300711cbf920c0b85555261993'::bytea, 23670618::numeric(78, 0)),

-- correction only relevant for the tests in the test_batch_rewards.py file
('ethereum', 'prod', 53::bigint, '\x02'::bytea, 500000000000000::numeric(78, 0))

) as temp(blockchain, environment, auction_id, token, price)
where blockchain = '{{blockchain}}' and environment = '{{environment}}'
),
18 changes: 15 additions & 3 deletions queries/orderbook/barn_batch_rewards.sql
Original file line number Diff line number Diff line change
Expand Up @@ -95,18 +95,30 @@ trade_data_processed as (
from trade_data_unprocessed
),

{{auction_prices_corrections}}

auction_prices_processed as (
select
ap.auction_id,
ap.token,
coalesce(apc.price, ap.price) as price
from auction_prices as ap inner join observed_settlements as os on ap.auction_id = os.auction_id -- inner join done to speed up query
left outer join auction_prices_corrections as apc
on ap.auction_id = apc.auction_id and ap.token = apc.token
),

price_data as (
select
tdp.auction_id,
tdp.order_uid,
ap_surplus.price / pow(10, 18) as surplus_token_native_price,
ap_protocol.price / pow(10, 18) as protocol_fee_token_native_price,
ap_sell.price / pow(10, 18) as network_fee_token_native_price
from trade_data_processed as tdp left outer join auction_prices as ap_sell -- contains price: sell token
from trade_data_processed as tdp left outer join auction_prices_processed as ap_sell -- contains price: sell token
on tdp.auction_id = ap_sell.auction_id and tdp.sell_token = ap_sell.token
left outer join auction_prices as ap_surplus -- contains price: surplus token
left outer join auction_prices_processed as ap_surplus -- contains price: surplus token
on tdp.auction_id = ap_surplus.auction_id and tdp.surplus_token = ap_surplus.token
left outer join auction_prices as ap_protocol -- contains price: protocol fee token
left outer join auction_prices_processed as ap_protocol -- contains price: protocol fee token
on tdp.auction_id = ap_protocol.auction_id and tdp.surplus_token = ap_protocol.token
),

Expand Down
19 changes: 16 additions & 3 deletions queries/orderbook/order_data.sql
Original file line number Diff line number Diff line change
Expand Up @@ -119,6 +119,19 @@ trade_data_processed as (
on tdu.order_uid = pfk.order_uid and tdu.auction_id = pfk.auction_id
),

{{auction_prices_corrections}}

auction_prices_processed as (
select
ap.auction_id,
ap.token,
coalesce(apc.price, ap.price) as price
from auction_prices as ap inner join settlements as s on ap.auction_id = s.auction_id -- inner join done to speed up query
left outer join auction_prices_corrections as apc
on ap.auction_id = apc.auction_id and ap.token = apc.token
where s.block_number >= {{start_block}} and s.block_number <= {{end_block}}
),

price_data as (
select
tdp.auction_id,
Expand All @@ -127,11 +140,11 @@ price_data as (
ap_protocol.price / pow(10, 18) as protocol_fee_token_native_price,
ap_sell.price / pow(10, 18) as network_fee_token_native_price
from trade_data_processed as tdp
left outer join auction_prices as ap_sell -- contains price: sell token
left outer join auction_prices_processed as ap_sell -- contains price: sell token
on tdp.auction_id = ap_sell.auction_id and tdp.sell_token = ap_sell.token
left outer join auction_prices as ap_surplus -- contains price: surplus token
left outer join auction_prices_processed as ap_surplus -- contains price: surplus token
on tdp.auction_id = ap_surplus.auction_id and tdp.surplus_token = ap_surplus.token
left outer join auction_prices as ap_protocol -- contains price: protocol fee token
left outer join auction_prices_processed as ap_protocol -- contains price: protocol fee token
on tdp.auction_id = ap_protocol.auction_id and tdp.surplus_token = ap_protocol.token
),

Expand Down
18 changes: 15 additions & 3 deletions queries/orderbook/prod_batch_rewards.sql
Original file line number Diff line number Diff line change
Expand Up @@ -95,18 +95,30 @@ trade_data_processed as (
from trade_data_unprocessed
),

{{auction_prices_corrections}}

auction_prices_processed as (
select
ap.auction_id,
ap.token,
coalesce(apc.price, ap.price) as price
from auction_prices as ap inner join observed_settlements as os on ap.auction_id = os.auction_id
left outer join auction_prices_corrections as apc
on ap.auction_id = apc.auction_id and ap.token = apc.token
),

price_data as (
select
tdp.auction_id,
tdp.order_uid,
ap_surplus.price / pow(10, 18) as surplus_token_native_price,
ap_protocol.price / pow(10, 18) as protocol_fee_token_native_price,
ap_sell.price / pow(10, 18) as network_fee_token_native_price
from trade_data_processed as tdp left outer join auction_prices as ap_sell -- contains price: sell token
from trade_data_processed as tdp left outer join auction_prices_processed as ap_sell -- contains price: sell token
on tdp.auction_id = ap_sell.auction_id and tdp.sell_token = ap_sell.token
left outer join auction_prices as ap_surplus -- contains price: surplus token
left outer join auction_prices_processed as ap_surplus -- contains price: surplus token
on tdp.auction_id = ap_surplus.auction_id and tdp.surplus_token = ap_surplus.token
left outer join auction_prices as ap_protocol -- contains price: protocol fee token
left outer join auction_prices_processed as ap_protocol -- contains price: protocol fee token
on tdp.auction_id = ap_protocol.auction_id and tdp.surplus_token = ap_protocol.token
),

Expand Down
42 changes: 40 additions & 2 deletions src/fetch/orderbook.py
Original file line number Diff line number Diff line change
Expand Up @@ -88,6 +88,16 @@ def run_batch_data_query(
Fetches and validates Batch Data DataFrame as concatenation from Prod and Staging DB
"""
load_dotenv()
barn_auction_prices_corrections_str = (
open_query("orderbook/auction_prices_corrections.sql")
.replace("{{blockchain}}", config.dune_config.dune_blockchain)
.replace("{{environment}}", "barn")
)
prod_auction_prices_corrections_str = (
open_query("orderbook/auction_prices_corrections.sql")
.replace("{{blockchain}}", config.dune_config.dune_blockchain)
.replace("{{environment}}", "prod")
)
batch_data_query_prod = (
open_query("orderbook/prod_batch_rewards.sql")
.replace("{{start_block}}", str(block_range.block_from))
Expand All @@ -99,6 +109,9 @@ def run_batch_data_query(
"{{EPSILON_UPPER}}", str(config.reward_config.batch_reward_cap_upper)
)
.replace("{{results}}", "dune_sync_batch_data_table")
.replace(
"{{auction_prices_corrections}}", prod_auction_prices_corrections_str
)
)
batch_data_query_barn = (
open_query("orderbook/barn_batch_rewards.sql")
Expand All @@ -111,6 +124,9 @@ def run_batch_data_query(
"{{EPSILON_UPPER}}", str(config.reward_config.batch_reward_cap_upper)
)
.replace("{{results}}", "dune_sync_batch_data_table")
.replace(
"{{auction_prices_corrections}}", barn_auction_prices_corrections_str
)
)
data_types = {
# According to this: https://stackoverflow.com/a/11548224
Expand Down Expand Up @@ -164,21 +180,39 @@ def get_batch_data(
return pd.concat(res)

@classmethod
def run_order_data_query(cls, block_range: BlockRange) -> DataFrame:
def run_order_data_query(
cls, block_range: BlockRange, blockchain: str
) -> DataFrame:
"""
Fetches and validates Order Data DataFrame as concatenation from Prod and Staging DB
"""
barn_auction_prices_corrections_str = (
open_query("orderbook/auction_prices_corrections.sql")
.replace("{{blockchain}}", blockchain)
.replace("{{environment}}", "barn")
)
prod_auction_prices_corrections_str = (
open_query("orderbook/auction_prices_corrections.sql")
.replace("{{blockchain}}", blockchain)
.replace("{{environment}}", "prod")
)
cow_reward_query_prod = (
open_query("orderbook/order_data.sql")
.replace("{{start_block}}", str(block_range.block_from))
.replace("{{end_block}}", str(block_range.block_to))
.replace("{{env}}", "prod")
.replace(
"{{auction_prices_corrections}}", prod_auction_prices_corrections_str
)
)
cow_reward_query_barn = (
open_query("orderbook/order_data.sql")
.replace("{{start_block}}", str(block_range.block_from))
.replace("{{end_block}}", str(block_range.block_to))
.replace("{{env}}", "barn")
.replace(
"{{auction_prices_corrections}}", barn_auction_prices_corrections_str
)
)
data_types = {"block_number": "int64", "amount": "float64"}
barn, prod = cls._query_both_dbs(
Expand Down Expand Up @@ -219,7 +253,11 @@ def get_order_data(
log.info(f"About to process block range ({start}, {start + size - 1})")
res.append(
cls.run_order_data_query(
BlockRange(block_from=start, block_to=start + size - 1)
BlockRange(
block_from=start,
block_to=start + size - 1,
),
config.dune_config.dune_blockchain,
)
)
start = start + size
Expand Down
1 change: 1 addition & 0 deletions src/fetch/payouts.py
Original file line number Diff line number Diff line change
Expand Up @@ -731,6 +731,7 @@ def construct_payouts(
dune.end_block,
config.reward_config.batch_reward_cap_upper,
config.reward_config.batch_reward_cap_lower,
config.dune_config.dune_blockchain,
)
)
service_fee_df = DataFrame(dune.get_service_fee_status())
Expand Down
20 changes: 19 additions & 1 deletion src/pg_client.py
Original file line number Diff line number Diff line change
Expand Up @@ -42,23 +42,37 @@ def exec_query(cls, query: str, engine: Engine) -> DataFrame:
"""Executes query on DB engine"""
return pd.read_sql(sql=query, con=engine)

def get_solver_rewards(
def get_solver_rewards( # pylint: disable=too-many-arguments, too-many-positional-arguments
self,
start_block: str,
end_block: str,
reward_cap_upper: int,
reward_cap_lower: int,
blockchain: str,
) -> DataFrame:
"""
Returns aggregated solver rewards for accounting period defined by block range
"""
prod_auction_prices_corrections_str = (
open_query("orderbook/auction_prices_corrections.sql")
.replace("{{blockchain}}", blockchain)
.replace("{{environment}}", "prod")
)
barn_auction_prices_corrections_str = (
open_query("orderbook/auction_prices_corrections.sql")
.replace("{{blockchain}}", blockchain)
.replace("{{environment}}", "barn")
)
batch_reward_query_prod = (
open_query("orderbook/prod_batch_rewards.sql")
.replace("{{start_block}}", start_block)
.replace("{{end_block}}", end_block)
.replace("{{EPSILON_LOWER}}", str(reward_cap_lower))
.replace("{{EPSILON_UPPER}}", str(reward_cap_upper))
.replace("{{results}}", "solver_rewards_script_table")
.replace(
"{{auction_prices_corrections}}", prod_auction_prices_corrections_str
)
)
batch_reward_query_barn = (
open_query("orderbook/barn_batch_rewards.sql")
Expand All @@ -67,7 +81,11 @@ def get_solver_rewards(
.replace("{{EPSILON_LOWER}}", str(reward_cap_lower))
.replace("{{EPSILON_UPPER}}", str(reward_cap_upper))
.replace("{{results}}", "solver_rewards_script_table")
.replace(
"{{auction_prices_corrections}}", barn_auction_prices_corrections_str
)
)

results = []

# querying the prod database
Expand Down
2 changes: 1 addition & 1 deletion tests/queries/batch_rewards_test_db.sql
Original file line number Diff line number Diff line change
Expand Up @@ -206,7 +206,7 @@ VALUES (51, '\x01', 500000000000000000000000000),
(52, '\x01', 500000000000000000000000000),
(52, '\x02', 500000000000000),
(53, '\x01', 500000000000000000000000000),
(53, '\x02', 500000000000000),
(53, '\x02', 5000000000000000000000000000000000000),
(54, '\x01', 500000000000000000000000000),
(54, '\x02', 500000000000000),
(55, '\x01', 500000000000000000000000000),
Expand Down
2 changes: 2 additions & 0 deletions tests/queries/test_batch_rewards.py
Original file line number Diff line number Diff line change
Expand Up @@ -24,11 +24,13 @@ def setUp(self) -> None:

def test_get_batch_rewards(self):
start_block, end_block = "0", "100"
blockchain = "ethereum"
batch_rewards = self.fetcher.get_solver_rewards(
start_block,
end_block,
self.batch_reward_cap_upper,
self.batch_reward_cap_lower,
blockchain,
)
expected = DataFrame(
{
Expand Down

0 comments on commit be8716d

Please sign in to comment.