Skip to content

Commit

Permalink
Add integrator fees accounting and transfers (#356)
Browse files Browse the repository at this point in the history
This PR adds the integrator fees transfers, with a hardcoded 85%-15%
split between integrator and the protocol.

There is also a minor unrelated change regarding the default min COW
transfer amount, which is now set to the same constant (20 COW) as the
one used in the weekly payout script.

---------

Co-authored-by: Felix Henneke <felix.henneke@protonmail.com>
  • Loading branch information
harisang and fhenneke authored Apr 21, 2024
1 parent 24c355b commit 18de228
Show file tree
Hide file tree
Showing 8 changed files with 200 additions and 40 deletions.
52 changes: 43 additions & 9 deletions queries/orderbook/barn_batch_rewards.sql
Original file line number Diff line number Diff line change
Expand Up @@ -55,7 +55,8 @@ order_surplus AS (
CASE
WHEN o.kind = 'sell' THEN o.buy_token
WHEN o.kind = 'buy' THEN o.sell_token
END AS surplus_token
END AS surplus_token,
ad.full_app_data as app_data
FROM
settlements s
JOIN settlement_scores ss -- contains block_deadline
Expand All @@ -69,6 +70,8 @@ order_surplus AS (
AND s.auction_id = oe.auction_id
LEFT OUTER JOIN order_quotes oq -- contains quote amounts
ON o.uid = oq.order_uid
LEFT OUTER JOIN app_data ad
on o.app_data = ad.contract_app_data
WHERE
ss.block_deadline >= {{start_block}}
AND ss.block_deadline <= {{end_block}}
Expand All @@ -78,12 +81,15 @@ order_protocol_fee AS (
os.auction_id,
os.solver,
os.tx_hash,
os.order_uid,
os.sell_amount,
os.buy_amount,
os.sell_token,
os.observed_fee,
os.surplus,
os.surplus_token,
convert_from(os.app_data, 'UTF8')::JSONB->'metadata'->'partnerFee'->>'recipient' as partner_fee_recipient,
fp.kind as protocol_fee_kind,
CASE
WHEN fp.kind = 'surplus' THEN CASE
WHEN os.kind = 'sell' THEN
Expand Down Expand Up @@ -140,18 +146,23 @@ order_protocol_fee AS (
),
order_protocol_fee_prices AS (
SELECT
opf.auction_id,
opf.solver,
opf.tx_hash,
opf.order_uid,
opf.surplus,
opf.protocol_fee,
opf.protocol_fee_token,
opf.partner_fee_recipient,
opf.protocol_fee_kind,
CASE
WHEN opf.sell_token != opf.protocol_fee_token THEN (opf.sell_amount - opf.observed_fee) / opf.buy_amount * opf.protocol_fee
ELSE opf.protocol_fee
END AS network_fee_correction,
opf.sell_token as network_fee_token,
ap_surplus.price / pow(10, 18) as surplus_token_price,
ap_protocol.price / pow(10, 18) as protocol_fee_token_price,
ap_sell.price / pow(10, 18) as network_fee_token_price
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
order_protocol_fee opf
JOIN auction_prices ap_sell -- contains price: sell token
Expand All @@ -169,8 +180,8 @@ batch_protocol_fees AS (
solver,
tx_hash,
-- sum(surplus * surplus_token_price) as surplus,
sum(protocol_fee * protocol_fee_token_price) as protocol_fee,
sum(network_fee_correction * network_fee_token_price) as network_fee_correction
sum(protocol_fee * protocol_fee_token_native_price) as protocol_fee,
sum(network_fee_correction * network_fee_token_native_price) as network_fee_correction
FROM
order_protocol_fee_prices
group by
Expand Down Expand Up @@ -214,9 +225,11 @@ reward_data AS (
0
) as network_fee_correction
FROM
settlement_scores ss -- If there are reported scores,
settlement_scores ss
-- If there are reported scores,
-- there will always be a record of auction participants
JOIN auction_participation ap ON ss.auction_id = ap.auction_id -- outer joins made in order to capture non-existent settlements.
JOIN auction_participation ap ON ss.auction_id = ap.auction_id
-- outer joins made in order to capture non-existent settlements.
LEFT OUTER JOIN observed_settlements os ON os.auction_id = ss.auction_id
LEFT OUTER JOIN batch_protocol_fees bpf ON bpf.tx_hash = os.tx_hash
),
Expand Down Expand Up @@ -273,16 +286,37 @@ primary_rewards as (
GROUP BY
solver
),
partner_fees_per_solver AS (
SELECT
solver,
partner_fee_recipient,
sum(protocol_fee * protocol_fee_token_native_price) as protocol_fee_eth
FROM
order_protocol_fee_prices
WHERE partner_fee_recipient is not null
group by solver,partner_fee_recipient
),
aggregate_partner_fees_per_solver AS (
SELECT
solver,
array_agg(parter_fee_recipient) as partner_list,
array_agg(protocol_fee_eth) as partner_payments_in_eth
FROM partner_fees_per_solver
group by solver
),
aggregate_results as (
SELECT
concat('0x', encode(pc.solver, 'hex')) as solver,
coalesce(payment, 0) as primary_reward_eth,
num_participating_batches,
coalesce(protocol_fee, 0) as protocol_fee_eth,
coalesce(network_fee, 0) as network_fee_eth
coalesce(network_fee, 0) as network_fee_eth,
partner_list,
partner_payments_in_eth
FROM
participation_counts pc
LEFT OUTER JOIN primary_rewards pr ON pr.solver = pc.solver
LEFT OUTER JOIN aggregate_partner_fees_per_solver aif on pr.solver = aif.solver
) --
select
*
Expand Down
32 changes: 30 additions & 2 deletions queries/orderbook/prod_batch_rewards.sql
Original file line number Diff line number Diff line change
Expand Up @@ -55,7 +55,8 @@ order_surplus AS (
CASE
WHEN o.kind = 'sell' THEN o.buy_token
WHEN o.kind = 'buy' THEN o.sell_token
END AS surplus_token
END AS surplus_token,
ad.full_app_data as app_data
FROM
settlements s
JOIN settlement_scores ss -- contains block_deadline
Expand All @@ -69,6 +70,8 @@ order_surplus AS (
AND s.auction_id = oe.auction_id
LEFT OUTER JOIN order_quotes oq -- contains quote amounts
ON o.uid = oq.order_uid
LEFT OUTER JOIN app_data ad
on o.app_data = ad.contract_app_data
WHERE
ss.block_deadline >= {{start_block}}
AND ss.block_deadline <= {{end_block}}
Expand All @@ -85,6 +88,8 @@ order_protocol_fee AS (
os.observed_fee,
os.surplus,
os.surplus_token,
convert_from(os.app_data, 'UTF8')::JSONB->'metadata'->'partnerFee'->>'recipient' as partner_fee_recipient,
fp.kind as protocol_fee_kind,
CASE
WHEN fp.kind = 'surplus' THEN CASE
WHEN os.kind = 'sell' THEN
Expand Down Expand Up @@ -148,6 +153,8 @@ order_protocol_fee_prices AS (
opf.surplus,
opf.protocol_fee,
opf.protocol_fee_token,
opf.partner_fee_recipient,
opf.protocol_fee_kind,
CASE
WHEN opf.sell_token != opf.protocol_fee_token THEN (opf.sell_amount - opf.observed_fee) / opf.buy_amount * opf.protocol_fee
ELSE opf.protocol_fee
Expand Down Expand Up @@ -279,16 +286,37 @@ primary_rewards as (
GROUP BY
solver
),
partner_fees_per_solver AS (
SELECT
solver,
partner_fee_recipient,
sum(protocol_fee * protocol_fee_token_native_price) as protocol_fee_eth
FROM
order_protocol_fee_prices
WHERE partner_fee_recipient is not null
group by solver,partner_fee_recipient
),
aggregate_partner_fees_per_solver AS (
SELECT
solver,
array_agg(partner_fee_recipient) as partner_list,
array_agg(protocol_fee_eth) as partner_payments_in_eth
FROM partner_fees_per_solver
group by solver
),
aggregate_results as (
SELECT
concat('0x', encode(pc.solver, 'hex')) as solver,
coalesce(payment, 0) as primary_reward_eth,
num_participating_batches,
coalesce(protocol_fee, 0) as protocol_fee_eth,
coalesce(network_fee, 0) as network_fee_eth
coalesce(network_fee, 0) as network_fee_eth,
partner_list,
partner_payments_in_eth
FROM
participation_counts pc
LEFT OUTER JOIN primary_rewards pr ON pr.solver = pc.solver
LEFT OUTER JOIN aggregate_partner_fees_per_solver aif on pr.solver = aif.solver
) --
select
*
Expand Down
86 changes: 76 additions & 10 deletions src/fetch/payouts.py
Original file line number Diff line number Diff line change
Expand Up @@ -295,7 +295,13 @@ def extend_payment_df(pdf: DataFrame, converter: TokenConversion) -> DataFrame:
return pdf


def prepare_transfers(payout_df: DataFrame, period: AccountingPeriod) -> PeriodPayouts:
def prepare_transfers(
payout_df: DataFrame,
period: AccountingPeriod,
final_protocol_fee_wei: int,
partner_fee_tax_wei: int,
partner_fees_wei: dict[str, int],
) -> PeriodPayouts:
"""
Manipulates the payout DataFrame to split into ETH and COW.
Specifically, We deduct total_rewards by total_execution_cost (both initially in ETH)
Expand All @@ -318,13 +324,30 @@ def prepare_transfers(payout_df: DataFrame, period: AccountingPeriod) -> PeriodP
overdrafts.append(overdraft)
transfers += payout_datum.as_payouts()

transfers.append(
Transfer(
token=None,
recipient=PROTOCOL_FEE_SAFE,
amount_wei=int(payout_df.protocol_fee_eth.sum()),
if final_protocol_fee_wei > 0:
transfers.append(
Transfer(
token=None,
recipient=PROTOCOL_FEE_SAFE,
amount_wei=final_protocol_fee_wei,
)
)
if partner_fee_tax_wei > 0:
transfers.append(
Transfer(
token=None,
recipient=PROTOCOL_FEE_SAFE,
amount_wei=partner_fee_tax_wei,
)
)
for address in partner_fees_wei:
transfers.append(
Transfer(
token=None,
recipient=Address(address),
amount_wei=partner_fees_wei[address],
)
)
)

return PeriodPayouts(overdrafts, transfers)

Expand Down Expand Up @@ -390,12 +413,17 @@ def construct_payouts(
dune: DuneFetcher, orderbook: MultiInstanceDBFetcher
) -> list[Transfer]:
"""Workflow of solver reward payout logic post-CIP27"""
# pylint: disable-msg=too-many-locals

price_day = dune.period.end - timedelta(days=1)
reward_token = TokenId.COW

quote_rewards_df = orderbook.get_quote_rewards(dune.start_block, dune.end_block)
batch_rewards_df = orderbook.get_solver_rewards(dune.start_block, dune.end_block)
partner_fees_df = batch_rewards_df[["partner_list", "partner_payments_in_eth"]]
batch_rewards_df = batch_rewards_df.drop(
["partner_list", "partner_payments_in_eth"], axis=1
)
merged_df = pandas.merge(
quote_rewards_df, batch_rewards_df, on="solver", how="outer"
).fillna(0)
Expand All @@ -420,15 +448,53 @@ def construct_payouts(
performance_reward = complete_payout_df["primary_reward_cow"].sum()
participation_reward = complete_payout_df["secondary_reward_cow"].sum()
quote_reward = complete_payout_df["quote_reward_cow"].sum()
protocol_fee = complete_payout_df["protocol_fee_eth"].sum()
raw_protocol_fee_wei = int(complete_payout_df.protocol_fee_eth.sum())

# We now decompose the raw_protocol_fee_wei amount into actual
# protocol fee and partner fees. For convenience,
# we use a dictionary partner_fees_wei that contains the the
# destination address of an partner as a key, and the value is the
# amount in wei to be transferred to that address, stored as an int.

partner_fees_wei: dict[str, int] = {}
for _, row in partner_fees_df.iterrows():
if row["partner_list"] is None:
continue

# We assume the two lists used below, i.e.,
# partner_list and partner_payments_in_eth,
# are "aligned".

for i in range(len(row["partner_list"])):
address = row["partner_list"][i]
if address in partner_fees_wei:
partner_fees_wei[address] += int(row["partner_payments_in_eth"][i])
else:
partner_fees_wei[address] = int(row["partner_payments_in_eth"][i])
total_partner_fee_wei = 0
for address, value in partner_fees_wei.items():
total_partner_fee_wei += value
partner_fees_wei[address] = int(0.85 * value)

final_protocol_fee_wei = raw_protocol_fee_wei - total_partner_fee_wei
partner_fee_tax_wei = int(0.15 * total_partner_fee_wei)
total_partner_fee_wei = int(0.85 * total_partner_fee_wei)
dune.log_saver.print(
f"Performance Reward: {performance_reward / 10 ** 18:.4f}\n"
f"Participation Reward: {participation_reward / 10 ** 18:.4f}\n"
f"Quote Reward: {quote_reward / 10 ** 18:.4f}\n"
f"Protocol Fees: {protocol_fee / 10 ** 18:.4f}\n",
f"Protocol Fees: {final_protocol_fee_wei / 10 ** 18:.4f}\n"
f"Partner Fees Tax: {partner_fee_tax_wei / 10 ** 18:.4f}\n"
f"Partner Fees: {total_partner_fee_wei / 10 ** 18:.4f}\n",
category=Category.TOTALS,
)
payouts = prepare_transfers(complete_payout_df, dune.period)
payouts = prepare_transfers(
complete_payout_df,
dune.period,
final_protocol_fee_wei,
partner_fee_tax_wei,
partner_fees_wei,
)
for overdraft in payouts.overdrafts:
dune.log_saver.print(str(overdraft), Category.OVERDRAFT)
return payouts.transfers
2 changes: 1 addition & 1 deletion src/utils/script_args.py
Original file line number Diff line number Diff line change
Expand Up @@ -67,7 +67,7 @@ def generic_script_init(description: str) -> ScriptArgs:
"--min-transfer-amount-cow-atoms",
type=int,
help="Ignore COW transfers with amount less than this",
default=100000000000000000000,
default=20000000000000000000,
)
args = parser.parse_args()
return ScriptArgs(
Expand Down
Loading

0 comments on commit 18de228

Please sign in to comment.