polygon-models/models/silver/defi/lending/compound/silver__comp_repayments.sql
drethereum 9514a0d7ff
AN-4280/heal-logic (#366)
* vars

* tx success

* bridge heal

* typo

* cte name

* lps heal

* var format

* heal logic

* dex swaps heal

* column names

* round in gold
2024-05-29 11:30:28 -06:00

103 lines
2.8 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') }}
),
repayments 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 asset,
CONCAT('0x', SUBSTR(topics [1] :: STRING, 27, 40)) AS repayer,
CONCAT('0x', SUBSTR(topics [2] :: STRING, 27, 40)) AS borrower,
utils.udf_hex_to_int(
segmented_data [0] :: STRING
) :: INTEGER AS amount,
utils.udf_hex_to_int(
segmented_data [1] :: STRING
) :: INTEGER AS usd_value,
origin_from_address AS depositor,
'Compound V3' AS compound_version,
compound_market_name,
compound_market_symbol,
compound_market_decimals,
C.underlying_asset_address AS underlying_asset,
C.underlying_asset_symbol,
'polygon' AS blockchain,
_log_id,
l._inserted_timestamp
FROM
{{ ref('silver__logs') }}
l
LEFT JOIN comp_assets C
ON contract_address = C.compound_market_address
WHERE
topics [0] = '0xd1cf3d156d5f8f0d50f6c122ed609cec09d35c9b9fb3fff6ea0959134dae424e' --Supply
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,
contract_address,
w.asset AS compound_market,
repayer,
borrower,
depositor,
underlying_asset AS token_address,
w.underlying_asset_symbol AS token_symbol,
amount AS amount_unadj,
amount / pow(
10,
w.compound_market_decimals
) AS amount,
compound_version,
blockchain,
_log_id,
_inserted_timestamp
FROM
repayments w qualify(ROW_NUMBER() over(PARTITION BY _log_id
ORDER BY
_inserted_timestamp DESC)) = 1