Skip to content

Commit

Permalink
Update Rollup Economics (duneanalytics#4857)
Browse files Browse the repository at this point in the history
* add zora revenue and new op chain cost

* Add gas used
  • Loading branch information
Jam516 authored Dec 4, 2023
1 parent 52399cd commit ca57bfd
Show file tree
Hide file tree
Showing 2 changed files with 50 additions and 9 deletions.
26 changes: 17 additions & 9 deletions models/rollup_economics/ethereum/l1_data_fees.sql
Original file line number Diff line number Diff line change
Expand Up @@ -19,7 +19,8 @@ with tx_batch_appends as (
t.hash,
(cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent,
p.price * (cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent_usd,
length(t.data) as data_length
length(t.data) as data_length,
gas_used
FROM
(
SELECT
Expand Down Expand Up @@ -99,7 +100,8 @@ with tx_batch_appends as (
t.hash,
(cast(t.gas_used as double) * (cast(t.gas_price as double) / 1e18)) as gas_spent,
p.price * (cast(t.gas_used as double) * (cast(t.gas_price as double) / 1e18)) as gas_spent_usd,
length(t.data) as data_length
length(t.data) as data_length,
t.gas_used
FROM
{{ source('ethereum','transactions') }} as t
INNER JOIN (
Expand All @@ -110,7 +112,7 @@ with tx_batch_appends as (
MAX(CASE WHEN submitter_type = 'L2OutputOracle' AND role_type = 'from_address' THEN address ELSE NULL END) AS "l2_output_oracle_from_address",
MAX(CASE WHEN submitter_type = 'L2OutputOracle' AND role_type = 'to_address' THEN address ELSE NULL END) AS "l2_output_oracle_to_address"
FROM {{ ref('addresses_ethereum_l2_batch_submitters') }}
WHERE protocol_name IN ('OP Mainnet', 'Base', 'Public Goods Network', 'Zora Network', 'Aevo')
WHERE protocol_name IN ('OP Mainnet', 'Base', 'Public Goods Network', 'Zora', 'Aevo', 'Mode', 'Lyra', 'Orderly Network')
GROUP BY protocol_name
) as op ON (
t."from" = op.l1_batch_inbox_from_address
Expand All @@ -135,7 +137,8 @@ with tx_batch_appends as (
t.hash,
(cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent,
p.price * (cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent_usd,
(length(t.data)) AS input_length
(length(t.data)) AS data_length,
gas_used
FROM {{ source('ethereum','transactions') }} AS t
INNER JOIN {{ source('prices','usd') }} p
ON p.minute = date_trunc('minute', t.block_time)
Expand All @@ -157,7 +160,8 @@ with tx_batch_appends as (
t.hash,
(cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent,
p.price * (cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent_usd,
(length(t.data)) AS input_length
(length(t.data)) AS data_length,
gas_used
FROM {{ source('ethereum','transactions') }} AS t
INNER JOIN {{ source('prices','usd') }} p
ON p.minute = date_trunc('minute', t.block_time)
Expand All @@ -179,7 +183,8 @@ with tx_batch_appends as (
t.hash,
(cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent,
p.price * (cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent_usd,
(length(t.data)) AS input_length
(length(t.data)) AS data_length,
gas_used
FROM {{ source('ethereum','transactions') }} AS t
INNER JOIN {{ source('prices','usd') }} p
ON p.minute = date_trunc('minute', t.block_time)
Expand All @@ -204,7 +209,8 @@ with tx_batch_appends as (
t.hash,
(cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent,
p.price * (cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent_usd,
(length(t.data)) AS input_length
(length(t.data)) AS data_length,
gas_used
FROM {{ source('ethereum','transactions') }} AS t
INNER JOIN {{ source('prices','usd') }} p
ON p.minute = date_trunc('minute', t.block_time)
Expand All @@ -228,7 +234,8 @@ with tx_batch_appends as (
t.hash,
(cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent,
p.price * (cast(gas_used as double) * (cast(gas_price as double) / 1e18)) as gas_spent_usd,
(length(t.data)) AS input_length
(length(t.data)) AS data_length,
gas_used
FROM {{ source('ethereum','transactions') }} AS t
INNER JOIN {{ source('prices','usd') }} p
ON p.minute = date_trunc('minute', t.block_time)
Expand Down Expand Up @@ -259,7 +266,8 @@ txs.hash,
bxs.time as block_time,
txs.data_length,
gas_spent,
gas_spent_usd
gas_spent_usd,
gas_used
FROM tx_batch_appends txs
INNER JOIN block_basefees bxs
ON txs.block_number = bxs.block_number
33 changes: 33 additions & 0 deletions models/rollup_economics/ethereum/l2_revenue.sql
Original file line number Diff line number Diff line change
Expand Up @@ -151,4 +151,37 @@ WHERE
{% else %}
AND t.block_time >= timestamp '2022-01-01'
{% endif %}
GROUP BY 1,2

UNION ALL

SELECT
date_trunc('day', t.block_time) AS day
, 'zora' AS name
, SUM(
CASE WHEN cast(t.gas_price as double) = cast(0 as double) THEN 0
ELSE (l1_fee + (cast(t.gas_used as double) * cast(t.gas_price as double))) /POWER(10,18)
END
) AS l2_rev
, SUM(
p.price *
(CASE WHEN cast(t.gas_price as double) = cast(0 as double) THEN 0
ELSE (l1_fee + (cast(t.gas_used as double) * cast(t.gas_price as double))) /POWER(10,18)
END)
) AS l2_rev_usd
FROM {{ source('zora','transactions') }} t
INNER JOIN {{ source('prices','usd') }} p
ON p.minute = date_trunc('minute', t.block_time)
AND p.blockchain is null
AND p.symbol = 'ETH'
{% if is_incremental() %}
AND {{incremental_predicate('p.minute')}}
{% endif %}
WHERE
1 = 1
{% if is_incremental() %}
AND {{incremental_predicate('t.block_time')}}
{% else %}
AND t.block_time >= timestamp '2023-06-12' --when zora network launched
{% endif %}
GROUP BY 1,2

0 comments on commit ca57bfd

Please sign in to comment.