mirror of
https://github.com/FlipsideCrypto/optimism-models.git
synced 2026-02-06 13:56:45 +00:00
* created core__ez_dex_swaps view * added synthetix swaps models and adjusted velodrome / sushi models for necessary ez_dex columns * fixed error in velo pools backfill seed causing duplicates * fixed issue with silver prices causing duplicate token_address * added univ3 pools and swaps models for integration into ez_dex_swaps * replaced null event_names with swap * added univ3 to dex_swaps and added not null event name test * updated gitignore for dbt-env * curve pools silver model * added incremental logic to curve pools table * adjusted data type on decimal column * updated curve_pools and added curve_swaps * case when for null event_name * removed dbt-env * snowflake tagging for ez_dex_swaps * added beethoven swaps and pools tables, and joined them to ez_dex_swaps * beethoven pools yml * removed column from synthetix swaps yml * recreated velodrome pools model using the reads udf * change event_name to reference topic * deleted velo_pools_backfill seed and hardcoded function sigs * changed udf_hex_to_int ref to ethereum.public * changed synthetix swaps to reference data instead of event inputs * changed event_input references to data in beethoven models * rounded usd values * modified tx_to logic in curve swaps * modified curve swaps for proper volumes
140 lines
3.3 KiB
SQL
140 lines
3.3 KiB
SQL
{{ config(
|
|
materialized = 'incremental',
|
|
unique_key = '_log_id',
|
|
cluster_by = ['_inserted_timestamp::DATE']
|
|
) }}
|
|
|
|
WITH logs AS (
|
|
|
|
SELECT
|
|
_log_id,
|
|
block_number,
|
|
block_timestamp,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
event_name,
|
|
event_index,
|
|
event_inputs,
|
|
topics,
|
|
DATA,
|
|
_inserted_timestamp :: TIMESTAMP AS _inserted_timestamp
|
|
FROM
|
|
{{ ref('silver__logs') }}
|
|
WHERE
|
|
tx_status = 'SUCCESS'
|
|
|
|
{% if is_incremental() %}
|
|
AND _inserted_timestamp >= (
|
|
SELECT
|
|
MAX(
|
|
_inserted_timestamp
|
|
)
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
transfers AS (
|
|
SELECT
|
|
_log_id,
|
|
block_number,
|
|
tx_hash,
|
|
block_timestamp,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address :: STRING AS contract_address,
|
|
event_inputs :from :: STRING AS from_address,
|
|
event_inputs :to :: STRING AS to_address,
|
|
event_inputs :value :: FLOAT AS raw_amount,
|
|
event_index,
|
|
_inserted_timestamp
|
|
FROM
|
|
logs
|
|
WHERE
|
|
event_name = 'Transfer'
|
|
AND raw_amount IS NOT NULL
|
|
),
|
|
find_missing_events AS (
|
|
SELECT
|
|
_log_id,
|
|
block_number,
|
|
tx_hash,
|
|
block_timestamp,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address :: STRING AS contract_address,
|
|
CONCAT('0x', SUBSTR(topics [1], 27, 40)) :: STRING AS from_address,
|
|
CONCAT('0x', SUBSTR(topics [2], 27, 40)) :: STRING AS to_address,
|
|
COALESCE(ethereum.public.udf_hex_to_int(topics [3] :: STRING), ethereum.public.udf_hex_to_int(SUBSTR(DATA, 3, 64))) :: FLOAT AS raw_amount,
|
|
event_index,
|
|
_inserted_timestamp
|
|
FROM
|
|
logs
|
|
WHERE
|
|
event_name IS NULL
|
|
AND contract_address IN (
|
|
SELECT
|
|
DISTINCT contract_address
|
|
FROM
|
|
transfers
|
|
)
|
|
AND topics [0] :: STRING = '0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'
|
|
),
|
|
all_transfers AS (
|
|
SELECT
|
|
_log_id,
|
|
tx_hash,
|
|
block_number,
|
|
block_timestamp,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
from_address,
|
|
to_address,
|
|
raw_amount,
|
|
event_index,
|
|
_inserted_timestamp
|
|
FROM
|
|
transfers
|
|
UNION ALL
|
|
SELECT
|
|
_log_id,
|
|
tx_hash,
|
|
block_number,
|
|
block_timestamp,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
contract_address,
|
|
from_address,
|
|
to_address,
|
|
raw_amount,
|
|
event_index,
|
|
_inserted_timestamp
|
|
FROM
|
|
find_missing_events
|
|
)
|
|
SELECT
|
|
_log_id,
|
|
block_number,
|
|
tx_hash,
|
|
origin_function_signature,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
block_timestamp,
|
|
contract_address,
|
|
from_address,
|
|
to_address,
|
|
raw_amount,
|
|
_inserted_timestamp,
|
|
event_index
|
|
FROM
|
|
all_transfers qualify(ROW_NUMBER() over(PARTITION BY _log_id
|
|
ORDER BY
|
|
_inserted_timestamp DESC)) = 1 |