external-models/models/defillama/silver/silver__defillama_perp_metrics.sql
Matt Romano fbc539e02b
Some checks failed
docs_update / docs_update (push) Has been cancelled
docs_update / notify-failure (push) Has been cancelled
dbt_run_scheduled_weekly / run_dbt_jobs (push) Has been cancelled
dbt_run_scheduled_weekly / notify-failure (push) Has been cancelled
dbt_test / run_dbt_jobs (push) Has been cancelled
dbt_run_daily_aptos_gas / run_dbt_jobs (push) Has been cancelled
dbt_run_streamline_daily / run_dbt_jobs (push) Has been cancelled
dbt_run_dev_refresh / run_dbt_jobs_refresh (push) Has been cancelled
dbt_run_scheduled_daily / run_dbt_jobs (push) Has been cancelled
dbt_run_defillama_history / run_dbt_jobs (push) Has been cancelled
dbt_run_scheduled_bi_hourly / run_dbt_jobs (push) Has been cancelled
dbt_test / notify-failure (push) Has been cancelled
dbt_run_daily_aptos_gas / notify-failure (push) Has been cancelled
dbt_run_streamline_daily / notify-failure (push) Has been cancelled
dbt_run_dev_refresh / run_dbt_jobs_udfs (push) Has been cancelled
dbt_run_dev_refresh / notify-failure (push) Has been cancelled
dbt_run_scheduled_daily / notify-failure (push) Has been cancelled
dbt_run_defillama_history / notify-failure (push) Has been cancelled
dbt_run_scheduled_bi_hourly / notify-failure (push) Has been cancelled
exclude-null-perp-responses (#145)
2025-10-10 09:24:16 -07:00

83 lines
2.4 KiB
SQL

-- depends_on: {{ ref('bronze__defillama_perp_metrics') }}
{{ config(
materialized = 'incremental',
unique_key = 'defillama_perp_metrics_id',
cluster_by = ['timestamp','protocol_id'],
tags = ['defillama']
) }}
with base_raw as (
select
data,
_inserted_timestamp
from
{% if is_incremental() %}
{{ ref('bronze__defillama_perp_metrics') }}
where _inserted_timestamp > (
select coalesce(max(_inserted_timestamp), '2025-01-01') from {{ this }}
)
AND DATA IS NOT NULL
{% else %}
{{ ref('bronze__defillama_perp_metrics_FR') }}
WHERE DATA IS NOT NULL
{% endif %}
),
base as (
select
_inserted_timestamp :: DATE AS timestamp,
DATA :defillamaId :: STRING AS protocol_id,
DATA :category :: STRING AS category,
DATA :name :: STRING AS name,
DATA :displayName :: STRING AS display_name,
DATA :module :: STRING AS module,
DATA :logo :: STRING AS logo,
DATA :chains AS chains,
DATA :protocolType :: STRING AS protocol_type,
DATA :methodologyURL :: STRING AS methodology_url,
DATA :methodology AS methodology,
DATA :parentProtocol :: STRING AS parent_protocol,
DATA :slug :: STRING AS slug,
DATA :linkedProtocols AS linked_protocols,
DATA :total24h :: FLOAT AS total_24h,
DATA :total48hto24h :: FLOAT AS total_48h_to_24h,
DATA :total7d :: FLOAT AS total_7d,
DATA :total30d :: FLOAT AS total_30d,
DATA :totalAllTime :: FLOAT AS total_all_time,
DATA :change_1d :: FLOAT AS change_1d,
DATA :totalDataChartBreakdown AS total_data_chart_breakdown,
_inserted_timestamp
from base_raw
where data:defillamaId IS NOT NULL
and TRY_CAST(data:defillamaId::STRING AS NUMBER) IS NOT NULL
)
select
timestamp,
protocol_id,
category,
name,
display_name,
module,
logo,
chains,
protocol_type,
methodology_url,
methodology,
parent_protocol,
slug as protocol_slug,
linked_protocols,
total_24h,
total_48h_to_24h,
total_7d,
total_30d,
total_all_time,
change_1d,
total_data_chart_breakdown,
{{ dbt_utils.generate_surrogate_key(
['protocol_id','timestamp']
) }} as defillama_perp_metrics_id,
_inserted_timestamp,
sysdate() as inserted_timestamp,
sysdate() as modified_timestamp,
'{{ invocation_id }}' as _invocation_id
from base
qualify row_number() over (partition by defillama_perp_metrics_id order by _inserted_timestamp desc) = 1