-
Notifications
You must be signed in to change notification settings - Fork 2
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Coincidence of Wants query #7
Merged
Merged
Changes from all commits
Commits
Show all changes
6 commits
Select commit
Hold shift + click to select a range
3d0c359
added queries for coincidence of wants
fhenneke 85b5a41
fix sqlfluff linting
fhenneke e3e816e
change price computation to use volumes directly
fhenneke 9932fc4
remove symmetrized cow definition
fhenneke 9a90316
fix typo
fhenneke ead402a
added reference to masters thesis in cow specific queries
fhenneke File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,4 @@ | ||
[sqlfluff:templater:jinja:context] | ||
start_time='2024-08-01 12:00' | ||
end_time='2024-08-02 12:00' | ||
blockchain='ethereum' |
241 changes: 241 additions & 0 deletions
241
cowprotocol/coincidence_of_wants/balance_changes_4021257.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,241 @@ | ||
-- This is a base query for monitoring balance changes on CoW Protocol | ||
-- | ||
-- The query collects all balance changes to the settlement contract. Those changes can come from | ||
-- - erc20 transfers | ||
-- - native transfers | ||
-- - chain specific event like deposits and withdrawals | ||
-- | ||
-- Parameters: | ||
-- {{start_time}} - the timestamp for which the analysis should start (inclusively) | ||
-- {{end_time}} - the timestamp for which the analysis should end (exclusively) | ||
-- {{blockchain}} - network to run the analysis on | ||
-- | ||
-- The columns of the result are: | ||
-- - block_time: time of settlement transaction | ||
-- - tx_hash: settlement transaction hash | ||
-- - token_address: address of token with a balance change. contract address for erc20 tokens, | ||
-- 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee for native token | ||
-- - sender: origin of transfers sending tokens to the settlement contract, | ||
-- 0x0000000000000000000000000000000000000000 for deposits/withdrawals | ||
-- - receiver: destination of transfer sending tokens from the settlement contract, | ||
-- 0x0000000000000000000000000000000000000000 for deposits/withdrawals | ||
-- - amount: value of the balance change in atoms of the token | ||
|
||
-- 1) data on all chains | ||
-- 1.1) erc20 | ||
-- 1.2) native transfers | ||
|
||
-- 1.1) all the erc20 transfers to/from cow amms | ||
with erc20_transfers as ( | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
"from" as sender, | ||
to as receiver, | ||
value as amount | ||
from erc20_{{blockchain}}.evt_transfer | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 in ("from", to) | ||
), | ||
|
||
-- 1.2) all native token transfers | ||
native_transfers as ( | ||
select | ||
block_time, | ||
tx_hash, | ||
0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee as token_address, | ||
"from" as sender, | ||
to as receiver, | ||
value as amount | ||
from {{blockchain}}.traces | ||
where | ||
block_time >= cast('{{start_time}}' as timestamp) and block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and value > cast(0 as uint256) | ||
and success = true | ||
and 0x9008d19f58aabd9ed0d60971565aa8510560ab41 in (to, "from") | ||
), | ||
|
||
-- 2) chain specific data | ||
-- 2.1) ethereum | ||
-- special treatmet of | ||
-- 2.1.1) WETH | ||
-- 2.1.2) sDAI | ||
|
||
-- 2.1.1) all deposit and withdrawal events for WETH | ||
weth_deposits_withdrawals_ethereum as ( | ||
-- deposits (contract deposits ETH to get WETH) | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
0x0000000000000000000000000000000000000000 as sender, | ||
0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, | ||
wad as amount | ||
from zeroex_ethereum.WETH9_evt_Deposit | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and dst = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 | ||
union distinct | ||
-- withdrawals (contract withdraws ETH by returning WETH) | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, | ||
0x0000000000000000000000000000000000000000 as receiver, | ||
wad as amount | ||
from zeroex_ethereum.WETH9_evt_Withdrawal | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and src = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 | ||
), | ||
|
||
-- 2.1.2) all deposit and withdrawal events for sDAI | ||
sdai_deposits_withdraws_ethereum as ( | ||
-- deposits | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
0x0000000000000000000000000000000000000000 as sender, | ||
0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, | ||
shares as amount_wei | ||
from maker_ethereum.SavingsDai_evt_Deposit | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 | ||
union distinct | ||
-- withdraws | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, | ||
0x0000000000000000000000000000000000000000 as receiver, | ||
shares as amount_wei | ||
from maker_ethereum.SavingsDai_evt_Withdraw | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 | ||
), | ||
|
||
special_balance_changes_ethereum as ( | ||
select * from weth_deposits_withdrawals_ethereum | ||
union all | ||
select * from sdai_deposits_withdraws_ethereum | ||
), | ||
|
||
-- 2.2) gnosis | ||
-- special treatmet of | ||
-- 2.2.1) WXDAI | ||
-- 2.2.2) sDAI | ||
|
||
-- 2.2.1) all deposit and withdrawal events for WXDAI | ||
wxdai_deposits_withdrawals_gnosis as ( | ||
-- deposits (contract deposits XDAI to get WXDAI) | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
0x0000000000000000000000000000000000000000 as sender, | ||
0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, | ||
wad as amount | ||
from wxdai_gnosis.WXDAI_evt_Deposit | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and dst = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 | ||
union distinct | ||
-- withdrawals (contract withdraws XDAI by returning WXDAI) | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, | ||
0x0000000000000000000000000000000000000000 as receiver, | ||
wad as amount | ||
from wxdai_gnosis.WXDAI_evt_Withdrawal | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and src = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 | ||
), | ||
|
||
-- 2.2.2) all deposit and withdrawal events for sDAI | ||
sdai_deposits_withdraws_gnosis as ( | ||
-- deposits | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
0x0000000000000000000000000000000000000000 as sender, | ||
0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, | ||
shares as amount_wei | ||
from sdai_gnosis.SavingsXDai_evt_Deposit | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 | ||
union distinct | ||
-- withdraws | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, | ||
0x0000000000000000000000000000000000000000 as receiver, | ||
shares as amount_wei | ||
from sdai_gnosis.SavingsXDai_evt_Withdraw | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 | ||
), | ||
|
||
special_balance_changes_gnosis as ( -- noqa: ST03 | ||
select * from wxdai_deposits_withdrawals_gnosis | ||
union all | ||
select * from sdai_deposits_withdraws_gnosis | ||
), | ||
|
||
-- 2.3) arbitrum | ||
-- special treatmet of | ||
-- 2.3.1) WETH | ||
|
||
-- 2.3.1) all deposit and withdrawal events for WETH | ||
weth_deposits_withdrawals_arbitrum as ( | ||
-- deposits (contract deposits ETH to get WETH) | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
0x0000000000000000000000000000000000000000 as sender, | ||
0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, | ||
wad as amount | ||
from mindgames_weth_arbitrum.WETH9_evt_Deposit | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and dst = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 | ||
union distinct | ||
-- withdrawals (contract withdraws ETH by returning WETH) | ||
select | ||
evt_block_time as block_time, | ||
evt_tx_hash as tx_hash, | ||
contract_address as token_address, | ||
0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, | ||
0x0000000000000000000000000000000000000000 as receiver, | ||
wad as amount | ||
from mindgames_weth_arbitrum.WETH9_evt_Withdrawal | ||
where | ||
evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column | ||
and src = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 | ||
), | ||
|
||
special_balance_changes_arbitrum as ( -- noqa: ST03 | ||
select * from weth_deposits_withdrawals_arbitrum | ||
) | ||
|
||
-- combine results | ||
select * from erc20_transfers | ||
union all | ||
select * from native_transfers | ||
union all | ||
select * from special_balance_changes_{{blockchain}} |
85 changes: 85 additions & 0 deletions
85
cowprotocol/coincidence_of_wants/classified_balance_changes_4021306.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,85 @@ | ||
-- This query is part of a base query for computing CoWs | ||
-- | ||
-- Parameters: | ||
-- {{start_time}} - the timestamp for which the analysis should start (inclusively) | ||
-- {{end_time}} - the timestamp for which the analysis should end (exclusively) | ||
-- {{blockchain}} - network to run the analysis on | ||
-- | ||
-- The query tags all transfers to and from the settlement contract as one of | ||
-- - user_in: amounts sent by users, tokens flowing into the settlement contract | ||
-- - user_out: amount sent to users, tokens flowing out of the settlement contract | ||
-- - amm_in: tokens flowing into the settlement contract but coming from users | ||
-- - amm_out:tokens flowing out of the settlement contract but not towards users | ||
-- - slippage_in: final imbalance of the settlement contract if that imbalance is positive | ||
-- - slippage_out: final imbalance of the settlement contract of that imbalance is negative | ||
-- | ||
-- The classification into user transfers and amm transfers depends on a clear separation of addresses into | ||
-- trader addresses and amm addresses. If an address is used in a trade, all interactions with that address | ||
-- are classified as user transfers, even in other transactions. | ||
-- | ||
-- The common edge case of the settlement contract acting as a trader is implicitly handled sa follows: | ||
-- The settlement contract will appear as a trader. There will be a transfer from the settlement contract to itself. | ||
-- The corresponding balance change is accounted for as 'user_in'. | ||
-- This behavior will be wrong when an order is created with receiver set to the settlement contract. | ||
|
||
with filtered_trades as ( | ||
select * | ||
from cow_protocol_{{blockchain}}.trades | ||
where block_time >= cast('{{start_time}}' as timestamp) and block_time < cast('{{end_time}}' as timestamp) | ||
), | ||
|
||
traders as ( | ||
select | ||
trader as sender, | ||
receiver | ||
from filtered_trades | ||
), | ||
|
||
balance_changes as ( | ||
select * | ||
from "query_4021257(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" | ||
), | ||
|
||
-- classify balance changes | ||
balance_changes_with_types as ( | ||
select | ||
block_time, | ||
tx_hash, | ||
token_address, | ||
amount, | ||
case | ||
-- user in | ||
when ( | ||
sender in (select sender from traders) -- transfer coming from a trader | ||
or sender = 0x40a50cf069e992aa4536211b23f286ef88752187 | ||
) -- transfer coming from ETH flow | ||
and receiver = 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 -- transfer going to the settlement contract | ||
then 'user_in' | ||
-- user out | ||
when | ||
receiver in (select receiver from traders) -- transfer going to a trader | ||
and sender = 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 -- transfer coming from the settlement contract | ||
then 'user_out' | ||
-- amm in | ||
when receiver = 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 | ||
then 'amm_in' | ||
-- amm out | ||
when sender = 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 | ||
then 'amm_out' | ||
end as transfer_type | ||
from balance_changes | ||
), | ||
|
||
slippage as ( | ||
select | ||
block_time, | ||
tx_hash, | ||
token_address, | ||
case when amount >= 0 then cast(amount as uint256) else cast(-amount as uint256) end as amount, | ||
case when amount >= 0 then 'slippage_in' else 'slippage_out' end as transfer_type | ||
from "query_4021644(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" | ||
) | ||
|
||
select * from balance_changes_with_types | ||
union all | ||
select * from slippage |
Oops, something went wrong.
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
I think we can definitely add a list parameter here (and have it
0x9008...
for this use case and*
for the other one).Given that this query does a lot of good edge case handling it would be great to combine it.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
I tried adding a list parameter but there seems to be an issue with using query results to populate it.
E.g. with this adapted query I get an error if I run this one:
Hard coding a list would work but then one has to keep track of CoW AMM addresses manually.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Yeah I think advanced features (like lists that are based on a query) are not supported.
What you could do is have one base query that takes a string or list with arbitrary options as a base and then have the "nice UX" query specify a list based off a query and call the base query with the selected value.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
I will tackle that when a new query using that base query is added to the repo.