mirror of
https://github.com/FlipsideCrypto/polygon-models.git
synced 2026-02-06 11:06:46 +00:00
* vars * tx success * bridge heal * typo * cte name * lps heal * var format * heal logic * dex swaps heal * column names * round in gold
110 lines
3.0 KiB
SQL
110 lines
3.0 KiB
SQL
{{ config(
|
|
materialized = 'incremental',
|
|
incremental_strategy = 'delete+insert',
|
|
unique_key = "block_number",
|
|
cluster_by = ['block_timestamp::DATE'],
|
|
tags = ['curated','reorg']
|
|
) }}
|
|
|
|
WITH
|
|
comp_assets as (
|
|
SELECT
|
|
compound_market_address,
|
|
compound_market_name,
|
|
compound_market_symbol,
|
|
compound_market_decimals,
|
|
underlying_asset_address,
|
|
underlying_asset_name,
|
|
underlying_asset_symbol,
|
|
underlying_asset_decimals
|
|
FROM
|
|
{{ ref('silver__comp_asset_details') }}
|
|
),
|
|
|
|
liquidations AS (
|
|
|
|
SELECT
|
|
tx_hash,
|
|
block_number,
|
|
block_timestamp,
|
|
event_index,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
origin_function_signature,
|
|
l.contract_address,
|
|
regexp_substr_all(SUBSTR(DATA, 3, len(DATA)), '.{64}') AS segmented_data,
|
|
l.contract_address AS compound_market,
|
|
CONCAT('0x', SUBSTR(topics [3] :: STRING, 27, 40)) AS asset,
|
|
CONCAT('0x', SUBSTR(topics [1] :: STRING, 27, 40)) AS absorber,
|
|
CONCAT('0x', SUBSTR(topics [2] :: STRING, 27, 40)) AS borrower,
|
|
utils.udf_hex_to_int(
|
|
segmented_data [0] :: STRING
|
|
) :: INTEGER AS collateral_absorbed,
|
|
utils.udf_hex_to_int(
|
|
segmented_data [1] :: STRING
|
|
) :: INTEGER AS usd_value,
|
|
origin_from_address AS depositor_address,
|
|
'Compound V3' AS compound_version,
|
|
C.token_name,
|
|
C.token_symbol,
|
|
C.token_decimals,
|
|
'polygon' AS blockchain,
|
|
_log_id,
|
|
l._inserted_timestamp
|
|
FROM
|
|
{{ ref('silver__logs') }}
|
|
l
|
|
LEFT JOIN {{ ref('silver__contracts') }} C
|
|
ON asset = C.contract_address
|
|
WHERE
|
|
topics [0] = '0x9850ab1af75177e4a9201c65a2cf7976d5d28e40ef63494b44366f86b2f9412e' --AbsorbCollateral
|
|
AND tx_status = 'SUCCESS'
|
|
AND l.contract_address IN (SELECT DISTINCT(compound_market_address) FROM comp_assets)
|
|
{% if is_incremental() %}
|
|
AND l._inserted_timestamp >= (
|
|
SELECT
|
|
MAX(
|
|
_inserted_timestamp
|
|
) - INTERVAL '12 hours'
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
)
|
|
SELECT
|
|
tx_hash,
|
|
block_number,
|
|
block_timestamp,
|
|
event_index,
|
|
origin_from_address,
|
|
origin_to_address,
|
|
origin_function_signature,
|
|
l.contract_address,
|
|
compound_market,
|
|
absorber,
|
|
borrower,
|
|
depositor_address,
|
|
asset AS token_address,
|
|
token_symbol,
|
|
collateral_absorbed AS amount_unadj,
|
|
collateral_absorbed / pow(
|
|
10,
|
|
token_decimals
|
|
) AS amount,
|
|
usd_value / pow(
|
|
10,
|
|
8
|
|
) AS amount_usd,
|
|
A.underlying_asset_address AS debt_asset,
|
|
A.underlying_asset_symbol AS debt_asset_symbol,
|
|
compound_version,
|
|
blockchain,
|
|
l._log_id,
|
|
l._inserted_timestamp
|
|
FROM
|
|
liquidations l
|
|
LEFT JOIN comp_assets A
|
|
ON l.compound_market = A.compound_market_address qualify(ROW_NUMBER() over(PARTITION BY _log_id
|
|
ORDER BY
|
|
_inserted_timestamp DESC)) = 1
|