AN-6455/improve-stablecoin-logic (#512)

* update to seed file

* add swaps model

* use cg seed and mapping

* update seed and add join logic for bridged and wrapped stable assets

* finalize model

* final tests and fixes

* add udf LQ model, update downstream

* remove db name from lq

* add tagged package

* delete seed
This commit is contained in:
Matt Romano 2025-07-30 13:14:08 -07:00 committed by GitHub
parent 78357f8e20
commit f8ae2f7688
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
5 changed files with 133 additions and 63 deletions

View File

@ -69,6 +69,7 @@ WITH stables AS (
token_address
FROM
{{ ref('silver__tokens_stablecoins') }}
where peg_type = 'peggedUSD'
),
xfer AS (
SELECT

View File

@ -0,0 +1,45 @@
{{ config(
materialized = 'incremental',
unique_key = ['id'],
cluster_by = ['pegType'],
merge_exclude_columns = ['inserted_timestamp'],
tags = ['weekly']
) }}
WITH raw_data AS (
SELECT
live.udf_api('https://raw.githubusercontent.com/DefiLlama/peggedassets-server/refs/heads/master/src/peggedData/peggedData.ts') AS raw,
PARSE_JSON(raw) :data :: STRING AS peggeddata_content
)
SELECT
id,
NAME,
address,
symbol,
onCoinGecko,
gecko_id,
cmcId,
pegType,
pegMechanism,
priceSource,
deadFrom,
delisted,
deprecated,
doublecounted,
SYSDATE() AS modified_timestamp,
SYSDATE() AS inserted_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
raw_data,
TABLE(
utils.udf_stablecoin_data_parse(
raw_data.peggeddata_content
)
)
{% if is_incremental() %}
WHERE id not in (
SELECT
id
FROM
{{ this }}
)
{% endif %}

View File

@ -1,70 +1,58 @@
{{ config(
materialized = 'incremental',
unique_key = ['blockchain', 'token_address','price_date'],
cluster_by = ['blockchain','price_date'],
unique_key = ['blockchain', 'token_address'],
cluster_by = ['blockchain'],
merge_exclude_columns = ['inserted_timestamp'],
tags = ['daily']
tags = ['weekly']
) }}
/*
This query finds stablecoins across chains that closely track USD (within 2%).
Token must have ALL THREE of the following:
2. Average deviation within 2% of $1 across the last 1000 hours
3. Median deviation within 2% of $1 across the last 1000 hours
*/
WITH price_comparisons AS (
WITH stablecoin_map AS (
SELECT
HOUR,
blockchain,
token_address,
price,
ABS(
price - 1
) AS usd_deviation
id,
gecko_id,
symbol,
pegType,
pegmechanism
FROM
{{ ref('price__ez_prices_hourly') }}
)
SELECT
date_day AS price_date,
blockchain,
token_address,
AVG(usd_deviation) AS avg_deviation,
MEDIAN(usd_deviation) AS median_deviation,
MIN(usd_deviation) AS min_deviation,
MAX(usd_deviation) AS max_deviation,
COUNT(*) AS hours_tracked
FROM
price_comparisons p
INNER JOIN {{ ref('core__dim_dates') }}
d
ON p.hour >= DATEADD(
'hour',
-1000,
d.date_day
)
AND p.hour < d.date_day
WHERE
token_address != '0x53fc82f14f009009b440a706e31c9021e1196a2f' -- BUIDL on avax?
{% if is_incremental() %}
-- Only process recent dates for incremental runs
AND d.date_day > (
SELECT
DATEADD('day', -7, MAX(price_date))
FROM
{{ this }})
AND d.date_day < CURRENT_DATE()
{% else %}
AND d.date_day >= '2025-01-01'
AND d.date_day < CURRENT_DATE()
{{ ref('silver__coingecko_stablecoin_map') }}
{% if is_incremental() %}
WHERE
id NOT IN (SELECT id FROM {{ this }})
{% endif %}
GROUP BY
date_day,
blockchain,
token_address
HAVING
avg_deviation BETWEEN 0
AND 0.02 -- Within 2% of $1
AND median_deviation BETWEEN 0
AND 0.02 -- Median within 2%
)
SELECT
c.id,
m.asset_id,
m.name,
m.symbol,
m.token_address,
coalesce(p.blockchain, m.blockchain) as blockchain,
C.pegType AS peg_type,
C.pegmechanism AS peg_mechanism,
m.modified_timestamp AS _inserted_timestamp,
SYSDATE() AS modified_timestamp,
SYSDATE() AS inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(['p.blockchain', 'm.token_address']) }} AS tokens_stablecoins_id,
'{{ invocation_id }}' AS _invocation_id
FROM
stablecoin_map C
INNER JOIN {{ ref('price__dim_asset_metadata') }}
m
ON m.asset_id = C.gecko_id
-- addition join logic to capture wrapped and bridged addresses
OR m.asset_id LIKE '%wrapped-' || C.gecko_id
OR m.asset_id LIKE '%bridged-' || C.gecko_id || '-' || m.blockchain
OR m.asset_id LIKE C.gecko_id || '-' || m.blockchain || '-bridged%'
OR m.asset_id LIKE '%bridged-' || LOWER(C.symbol) || '-' || m.blockchain || '%'
LEFT JOIN {{ ref('silver__provider_platform_blockchain_map') }}
p
ON m.blockchain = p.platform
WHERE
m.token_address IS NOT NULL
qualify ROW_NUMBER() over (
PARTITION BY p.blockchain,
m.token_address
ORDER BY
_inserted_timestamp DESC
) = 1

View File

@ -0,0 +1,36 @@
version: 2
models:
- name: silver__tokens_stablecoins
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- blockchain
- token_address
columns:
- name: asset_id
tests:
- not_null
- name: name
- name: symbol
tests:
- not_null
- name: token_address
tests:
- not_null
- name: blockchain
tests:
- not_null
- name: peg_type
tests:
- not_null
- name: peg_mechanism
tests:
- not_null
- name: _inserted_timestamp
- name: modified_timestamp
- name: inserted_timestamp
- name: tokens_stablecoins_id
tests:
- not_null
- unique
- name: _invocation_id

View File

@ -6,4 +6,4 @@ packages:
- package: dbt-labs/dbt_utils
version: 1.0.0
- git: https://github.com/FlipsideCrypto/fsc-utils.git
revision: "v1.36.1"
revision: v1.38.0