flashbots views (#49)

This commit is contained in:
Austin 2024-02-21 14:55:17 -05:00 committed by GitHub
parent e571cb8170
commit c501730ea9
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
14 changed files with 503 additions and 2 deletions

View File

@ -42,4 +42,4 @@ jobs:
dbt deps
- name: Run DBT Jobs
run: |
dbt run -m tag:defillama tag:deepnftvalue tag:core
dbt run -m tag:defillama tag:deepnftvalue tag:core tag:flashbots

View File

@ -0,0 +1,67 @@
{{ config (
materialized = 'view'
) }}
WITH meta AS (
SELECT
last_modified AS _inserted_timestamp,
file_name,
(
NULLIF(
CONCAT(
SPLIT_PART(SPLIT_PART(file_name, '/', 3), '-', 1),
SPLIT_PART(SPLIT_PART(file_name, '/', 3), '-', 2)
),
'mevshare_historical.csv'
) :: INTEGER
) AS _partition_by_month
FROM
TABLE(
information_schema.external_table_file_registration_history(
start_time => DATEADD('day', -3, CURRENT_TIMESTAMP()),
table_name => '{{ source( "flashbots", "mev") }}')
) A
)
SELECT
_inserted_timestamp,
block_number,
block_time,
block_hash,
extra_data,
fee_recipient_address,
bundle_id,
user_tx_hash,
user_tx_from,
user_tx_to,
backrun_tx_hash,
backrun_tx_from,
backrun_tx_to,
refund_tx_hash,
refund_from,
refund_to,
refund_value_eth,
s.value
FROM
{{ source(
"flashbots",
"mev"
) }}
s
JOIN meta b
ON b.file_name = metadata$filename
AND IFNULL(
b._partition_by_month,
0
) = IFNULL(
s._partition_by_month,
0
)
WHERE
IFNULL(
b._partition_by_month,
0
) = IFNULL(
s._partition_by_month,
0
)

View File

@ -0,0 +1,66 @@
{{ config (
materialized = 'view'
) }}
WITH meta AS (
SELECT
registered_on AS _inserted_timestamp,
file_name,
(
NULLIF(
CONCAT(
SPLIT_PART(SPLIT_PART(file_name, '/', 3), '-', 1),
SPLIT_PART(SPLIT_PART(file_name, '/', 3), '-', 2)
),
'mevshare_historical.csv'
) :: INTEGER
) AS _partition_by_month
FROM
TABLE(
information_schema.external_table_files(
table_name => '{{ source( "flashbots", "mev") }}'
)) A
)
SELECT
_inserted_timestamp,
block_number,
block_time,
block_hash,
extra_data,
fee_recipient_address,
bundle_id,
user_tx_hash,
user_tx_from,
user_tx_to,
backrun_tx_hash,
backrun_tx_from,
backrun_tx_to,
refund_tx_hash,
refund_from,
refund_to,
refund_value_eth,
s.value
FROM
{{ source(
"flashbots",
"mev"
) }}
s
JOIN meta b
ON b.file_name = metadata$filename
AND IFNULL(
b._partition_by_month,
0
) = IFNULL(
s._partition_by_month,
0
)
WHERE
IFNULL(
b._partition_by_month,
0
) = IFNULL(
s._partition_by_month,
0
)

View File

@ -0,0 +1,61 @@
{{ config (
materialized = 'view'
) }}
WITH meta AS (
SELECT
last_modified AS _inserted_timestamp,
file_name,
(
NULLIF(
CONCAT(
SPLIT_PART(SPLIT_PART(file_name, '/', 2), '-', 1),
SPLIT_PART(SPLIT_PART(file_name, '/', 2), '-', 2)
),
'protect_historical.csv'
) :: INTEGER
) AS _partition_by_month
FROM
TABLE(
information_schema.external_table_file_registration_history(
start_time => DATEADD('day', -3, CURRENT_TIMESTAMP()),
table_name => '{{ source( "flashbots", "protect") }}')
) A
)
SELECT
_inserted_timestamp,
tx_hash,
from_address,
to_address,
public_mempool,
created_at_block_number,
included_block_number,
tx_id,
hints_selected,
num_of_builders_shared,
refund_percent,
s.value
FROM
{{ source(
"flashbots",
"protect"
) }}
s
JOIN meta b
ON b.file_name = metadata$filename
AND IFNULL(
b._partition_by_month,
0
) = IFNULL(
s._partition_by_month,
0
)
WHERE
IFNULL(
b._partition_by_month,
0
) = IFNULL(
s._partition_by_month,
0
)

View File

@ -0,0 +1,60 @@
{{ config (
materialized = 'view'
) }}
WITH meta AS (
SELECT
registered_on AS _inserted_timestamp,
file_name,
(
NULLIF(
CONCAT(
SPLIT_PART(SPLIT_PART(file_name, '/', 2), '-', 1),
SPLIT_PART(SPLIT_PART(file_name, '/', 2), '-', 2)
),
'protect_historical.csv'
) :: INTEGER
) AS _partition_by_month
FROM
TABLE(
information_schema.external_table_files(
table_name => '{{ source( "flashbots", "protect") }}'
)) A
)
SELECT
_inserted_timestamp,
tx_hash,
from_address,
to_address,
public_mempool,
created_at_block_number,
included_block_number,
tx_id,
hints_selected,
num_of_builders_shared,
refund_percent,
s.value
FROM
{{ source(
"flashbots",
"protect"
) }}
s
JOIN meta b
ON b.file_name = metadata$filename
AND IFNULL(
b._partition_by_month,
0
) = IFNULL(
s._partition_by_month,
0
)
WHERE
IFNULL(
b._partition_by_month,
0
) = IFNULL(
s._partition_by_month,
0
)

View File

@ -0,0 +1,31 @@
{{ config(
materialized = "view",
tags = ['flashbots'],
meta={
'database_tags':{
'table': {
'PROTOCOL': 'flashbots'
}
}
}
) }}
SELECT
block_number,
block_time,
block_hash,
extra_data,
fee_recipient_address,
bundle_id,
user_tx_hash,
user_tx_from,
user_tx_to,
backrun_tx_hash,
backrun_tx_from,
backrun_tx_to,
refund_tx_hash,
refund_from,
refund_to,
refund_value_eth
FROM
{{ ref('silver__flashbots_mev_txs') }}

View File

@ -0,0 +1,43 @@
version: 2
models:
- name: flashbots__fact_mevshare_transactions
description: >
This table records all the landed backrun transactions on MEV-share, and its original user transaction that is being backrun, as well as the refund transaction where block builder send searcher's refund back to originating user.
These 3 transactions are settled in a bundle with the order of `(user_tx, backrun_tx, refund_tx)`.
MEV-share is the Order Flow Auction (OFA) product from Flashbots, resharing MEV profits back to users, with parameterized privacy features.
MEV-share inherit orderflow coming from Flashbots Protect RPC endpoint. Read more in [Flashbots docs](https://docs.flashbots.net/flashbots-protect/mev-share)!
columns:
- name: BLOCK_NUMBER
description: The number of the block in which transactions were included.
- name: BLOCK_TIME
description: The timestamp for when the block was mined.
- name: BLOCK_HASH
description: The hash of the block in which the MEV-share transactions landed.
- name: EXTRA_DATA
description: Additional data included in the block, often used for identifying the block builder.
- name: FEE_RECIPIENT_ADDRESS
description: The Ethereum address of the recipient of block rewards, which can be the block builder or validator.
- name: BUNDLE_ID
description: A row number partitioned by (`user_tx_hash`, `backrun_tx_hash`) to use as part of the deterministic id for refund bundles.
- name: USER_TX_HASH
description: The Ethereum hash of the user's protect transaction.
- name: USER_TX_FROM
description: The Ethereum address of the sender of the protect transaction.
- name: USER_TX_TO
description: The Ethereum address of the recipient of the protect transaction.
- name: BACKRUN_TX_HASH
description: The Ethereum hash of the transaction that backran the user's transaction in MEV-share OFA.
- name: BACKRUN_TX_FROM
description: The Ethereum address of the sender of the backrunning transaction.
- name: BACKRUN_TX_TO
description: The Ethereum address of the recipient of the backrunning transaction.
- name: REFUND_TX_HASH
description: The Ethereum hash of the refund transaction.
- name: REFUND_TX_FROM
description: The Ethereum address from which the refund was sent, which is always the block builder address.
- name: REFUND_TX_TO
description: The Ethereum address to which the refund was sent, which usually is user address but can be a different address user set when sending transaction to Flashbots Protect / MEV-share.
- name: REFUND_VALUE_ETH
description: The amount of ETH refunded to the protect transaction, as a result of a successful OFA backrun, depending on user's refund percentage setting when sending the transaction.

View File

@ -0,0 +1,25 @@
{{ config(
materialized = "view",
tags = ['flashbots'],
meta={
'database_tags':{
'table': {
'PROTOCOL': 'flashbots'
}
}
}
) }}
SELECT
tx_hash,
from_address,
to_address,
public_mempool,
created_at_block_number,
included_block_number,
tx_id,
hints_selected,
num_of_builders_shared,
refund_percent
FROM
{{ ref('silver__flashbots_protect_txs') }}

View File

@ -0,0 +1,28 @@
version: 2
models:
- name: flashbots__fact_protect_transactions
description: >
This table contains all the transactions received by Flashbots Protect RPC that are seen landed onchain, including the privacy setting user or application set when sending them.
Read more about Flashbots Protect from [documentation](https://docs.flashbots.net/flashbots-protect/quick-start) and [website](https://protect.flashbots.net/)!
columns:
- name: TX_HASH
description: The Ethereum transaction hash of the protect transaction.
- name: FROM_ADDRESS
description: The Ethereum address of the sender initiating the transaction.
- name: TO_ADDRESS
description: The Ethereum address of the recipient of the transaction.
- name: PUBLIC_MEMPOOL
description: A boolean indicating whether the transaction was initially visible in the public mempool. Source [mempool_dumpster](https://mempool-dumpster.flashbots.net/index.html)
- name: CREATED_AT_BLOCK_NUMBER
description: The block number at which the transaction was created (first received by Flashbots server). Note - Due to some reorg/simulation issues, there are some rows where `created_at_block_number` > `included_block_number`
- name: INCLUDED_BLOCK_NUMBER
description: The block number in which the transaction was included in the blockchain.
- name: TX_ID
description: A row number partitioned by (`tx_hash`, `created_at_block_number`, `included_block_number`) to use as part of the deterministic id for transactions who were submitted multiple times at same block, with different shared configs
- name: HINTS_SELECTED
description: The hints shared by the user for public streaming to searchers in the MEV-share orderflow auction (OFA).
- name: NUM_OF_BUILDERS_SHARED
description: The number of block builders the transaction was shared with, higher number will likely help faster inclusion speed onchain.
- name: REFUND_PERCENT
description: The percentage of OFA backrun profits refunded to the sender (user). The rest can be kept by builders or bided to payout to validator. Flashbots builders keeps 0 profit and send it to validator in the end of block payment transaction.

View File

@ -0,0 +1,43 @@
-- depends_on: {{ ref('bronze__flashbots_mev_txs') }}
{{ config(
materialized = "incremental",
unique_key = "_id",
cluster_by = "round(block_number,-3)",
tags = ['flashbots']
) }}
SELECT
block_number,
block_time,
block_hash,
extra_data,
fee_recipient_address,
bundle_id,
user_tx_hash,
LOWER(user_tx_from) AS user_tx_from,
LOWER(user_tx_to) AS user_tx_to,
backrun_tx_hash,
LOWER(backrun_tx_from) AS backrun_tx_from,
LOWER(backrun_tx_to) AS backrun_tx_to,
refund_tx_hash,
LOWER(refund_from) AS refund_from,
LOWER(refund_to) AS refund_to,
refund_value_eth,
_inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(
['user_tx_hash', 'backrun_tx_hash', 'bundle_id']
) }} AS _id
FROM
{% if is_incremental() %}
{{ ref('bronze__flashbots_mev_txs') }}
WHERE
_inserted_timestamp >= (
SELECT
MAX(_inserted_timestamp) _inserted_timestamp
FROM
{{ this }}
)
{% else %}
{{ ref('bronze__flashbots_mev_txs_fr') }}
{% endif %}

View File

@ -0,0 +1,20 @@
version: 2
models:
- name: silver__flashbots_mev_txs
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- _ID
columns:
- name: _INSERTED_TIMESTAMP
tests:
- not_null
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 2
- name: BLOCK_TIME
tests:
- not_null
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 2

View File

@ -0,0 +1,37 @@
-- depends_on: {{ ref('bronze__flashbots_protect_txs') }}
{{ config(
materialized = "incremental",
unique_key = "_id",
cluster_by = "round(included_block_number,-3)",
tags = ['flashbots']
) }}
SELECT
tx_hash,
LOWER(from_address) AS from_address,
LOWER(to_address) AS to_address,
public_mempool,
created_at_block_number,
included_block_number,
tx_id,
hints_selected,
num_of_builders_shared,
refund_percent,
_inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(
['tx_hash', 'created_at_block_number', 'included_block_number', 'tx_id']
) }} AS _id
FROM
{% if is_incremental() %}
{{ ref('bronze__flashbots_protect_txs') }}
WHERE
_inserted_timestamp >= (
SELECT
MAX(_inserted_timestamp) _inserted_timestamp
FROM
{{ this }}
)
{% else %}
{{ ref('bronze__flashbots_protect_txs_fr') }}
{% endif %}

View File

@ -0,0 +1,14 @@
version: 2
models:
- name: silver__flashbots_protect_txs
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- _ID
columns:
- name: _INSERTED_TIMESTAMP
tests:
- not_null
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 2

View File

@ -59,4 +59,10 @@ sources:
- name: l1_blocks
- name: l1_contracts
- name: l1_messages
- name: l1_storage_diffs
- name: l1_storage_diffs
- name: flashbots
database: streamline
schema: flashbots
tables:
- name: mev
- name: protect