Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Binary file added .DS_Store
Binary file not shown.
Binary file added models/.DS_Store
Binary file not shown.
64 changes: 64 additions & 0 deletions models/algorand/algorand__daily_balances.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,64 @@
{{
config(
materialized='incremental',
sort='block_timestamp',
unique_key='date || address',
incremental_strategy='delete+insert',
cluster_by=['date', 'address'],
tags=['snowflake', 'algorand', 'events']
)
}}

-- Get the average token price per hour
WITH prices AS (
SELECT
p.symbol,
date_trunc('day', recorded_at) as day,
avg(price) as price
FROM {{ source('shared', 'prices')}} p
WHERE
p.asset_id = 4030
{% if is_incremental() %}
AND recorded_at >= getdate() - interval '7 days'
{% else %}
AND recorded_at >= getdate() - interval '9 months'
{% endif %}
GROUP BY p.symbol, day
),

balances AS (
SELECT
b.address as address,
labels.address_name as address_name,
labels.project_name as address_label,
labels.l1_label as address_label_type,
labels.l2_label as address_label_subtype,
-- prices.price,
b.balance,
b.balance_type,
-- Value of the token in USD
prices.price * balance as balance_usd,
b.currency,
date
FROM
-- join against the clean daily balances table
{{ source('algorand', 'udm_daily_balances_algorand') }} b

LEFT OUTER JOIN
-- Labels for addresses
{{ source('shared', 'udm_address_labels_new') }} as labels
ON b.address = labels.address

LEFT OUTER JOIN
prices
ON prices.symbol = b.currency
AND date_trunc('day', b.date) = prices.day

WHERE
{% if is_incremental() %}
date >= getdate() - interval '7 days'
{% else %}
date >= getdate() - interval '9 months'
{% endif %}
)
SELECT * FROM balances ORDER BY date DESC
47 changes: 47 additions & 0 deletions models/algorand/algorand__tags.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,47 @@
{{
config(
materialized='incremental',
sort='block_timestamp',
unique_key='address',
incremental_strategy='delete+insert',
tags=['snowflake', 'algorand', 'events']
)
}}


SELECT sq.address,
'top-total-balance-holder' AS name,
'Top Holder' AS label
FROM (
SELECT
distinct sq_inner.address
FROM (
SELECT
blockchain,
date,
address,
balance,
currency,
row_number() over(partition by blockchain, address order by date desc) as rn
FROM {{ source('algorand', 'udm_daily_balances_algorand')}} udb
WHERE
blockchain = 'algorand'
-- Threshold check
AND balance >= 275000

-- Remove exchanges
AND address NOT IN (
SELECT address FROM {{ source('shared', 'udm_address_labels_new')}} WHERE blockchain = 'algorand' AND l1_label = 'cex'
)
-- Remove foundation
AND address NOT IN (
SELECT address FROM {{ source('shared', 'udm_address_labels_new')}} WHERE blockchain = 'algorand' AND l1_label = 'chadmin'
)
-- Remove foundation
AND address NOT IN (
SELECT address FROM {{ source('shared', 'udm_address_labels_new')}} WHERE blockchain = 'algorand' AND l1_label = 'operator'
)
AND date >= GETDATE() - interval'1 month'
) sq_inner
WHERE rn = 1
) sq
148 changes: 148 additions & 0 deletions models/algorand/algorand__udm_events.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,148 @@
{{
config(
materialized='incremental',
sort='block_timestamp',
unique_key='tx_id',
incremental_strategy='delete+insert',
tags=['snowflake', 'algorand', 'events']
)
}}

WITH prices AS (
SELECT
p.symbol,
date_trunc('hour', recorded_at) as hour,
avg(price) as price
FROM {{ source('shared', 'prices')}} p
WHERE
p.asset_id = 4030
{% if is_incremental() %}
AND recorded_at >= getdate() - interval '7 days'
{% else %}
AND recorded_at >= getdate() - interval '9 months'
{% endif %}
GROUP BY p.symbol, hour
),

tx_asset_type AS (
SELECT
-- blockchain,
-- block_timestamp,
-- block_number,
tx_id AS tx_id_asset,
CASE WHEN event_currency = 'ALGO' THEN 'ALGO' ELSE 'ASAs' END AS asset_type,
decimal_adjustment_asset,
price_asset
FROM (
SELECT DISTINCT
'algorand' as blockchain,
block_timestamp,
block_id as block_number,
tx_id,
coalesce(adj.symbol, event_currency) as event_currency,
adj.decimal_adjustment as decimal_adjustment_asset,
prices.price as price_asset
FROM {{ source('algorand', 'udm_events_algorand')}} e

LEFT OUTER JOIN {{ source('shared', 'udm_decimal_adjustments')}} adj
ON e.event_currency = adj.token_identifier AND adj.blockchain = 'algorand'

LEFT OUTER JOIN prices
ON prices.hour = date_trunc('hour', e.block_timestamp)
AND prices.symbol = e.event_currency

WHERE e.event_currency IS NOT NULL
AND
{% if is_incremental() %}
block_timestamp >= getdate() - interval '7 days'
{% else %}
block_timestamp >= getdate() - interval '9 months'
{% endif %}
AND decimal_adjustment_asset IS NOT NULL
)
)

SELECT
'algorand' as blockchain,
block_timestamp,
block_id as block_number,
tx_id,
tx_from,
tx_from_labels.l1_label as tx_from_label_type,
tx_from_labels.l2_label as tx_from_label_subtype,
tx_from_labels.project_name as tx_from_label,
tx_from_labels.address_name as tx_from_address_name,
tx_to,
tx_to_labels.l1_label as tx_to_label_type,
tx_to_labels.l2_label as tx_to_label_subtype,
tx_to_labels.project_name as tx_to_label,
tx_to_labels.address_name as tx_to_address_name,
tx_type,
CASE WHEN tx_asset_type.asset_type = 'ALGO' THEN tx_fee / pow(10, COALESCE(tx_asset_type.decimal_adjustment_asset, 0))
ELSE tx_fee / pow(10, COALESCE(adj.decimal_adjustment, 0))
END AS tx_fee,
-- tx_fee / pow(10, COALESCE(adj.decimal_adjustment, 0)) AS tx_fee,
-- CASE WHEN tx_id IN (SELECT DISTINCT tx_id FROM {{ source('algorand', 'udm_events_algorand')}} WHERE event_currency = 'ALGO') THEN tx_fee / pow(10, COALESCE(adj.decimal_adjustment, 0))
-- ELSE tx_fee END AS tx_fee,
-- CASE WHEN tx_id IN (SELECT DISTINCT tx_id FROM {{ source('algorand', 'udm_events_algorand')}} WHERE event_currency = 'ALGO') THEN tx_fee / pow(10, COALESCE(adj.decimal_adjustment, 0)) * prices.price
-- ELSE NULL END AS tx_fee_usd,
CASE WHEN tx_asset_type.asset_type = 'ALGO' THEN tx_fee / pow(10, COALESCE(tx_asset_type.decimal_adjustment_asset, 0)) * tx_asset_type.price_asset
ELSE tx_fee / pow(10, COALESCE(adj.decimal_adjustment, 0)) * prices.price
END AS tx_fee_usd,
-- tx_fee / pow(10, COALESCE(adj.decimal_adjustment, 0)) * prices.price AS tx_fee_usd,
event_from,
event_from_labels.l1_label as event_from_label_type,
event_from_labels.l2_label as event_from_label_subtype,
event_from_labels.project_name as event_from_label,
event_from_labels.address_name as event_from_address_name,
event_to,
event_to_labels.l1_label as event_to_label_type,
event_to_labels.l2_label as event_to_label_subtype,
event_to_labels.project_name as event_to_label,
event_to_labels.address_name as event_to_address_name,
event_type,
-- CASE WHEN tx_id IN (SELECT DISTINCT tx_id FROM {{ source('algorand', 'udm_events_algorand')}} WHERE event_currency = 'ALGO') THEN event_amount / pow(10, COALESCE(adj.decimal_adjustment, 0))
-- ELSE event_amount END AS event_amount,
event_amount / pow(10, COALESCE(adj.decimal_adjustment, 0)) AS event_amount,
-- CASE WHEN tx_id IN (SELECT DISTINCT tx_id FROM {{ source('algorand', 'udm_events_algorand')}} WHERE event_currency = 'ALGO') THEN event_amount / pow(10, COALESCE(adj.decimal_adjustment, 0)) * prices.price
-- ELSE NULL END AS event_amount_usd,
event_amount / pow(10, COALESCE(adj.decimal_adjustment, 0)) * prices.price AS event_amount_usd,
coalesce(adj.symbol, event_currency) as event_currency,
tx_asset_type.decimal_adjustment_asset,
tx_asset_type.price_asset
FROM {{ source('algorand', 'udm_events_algorand')}} e

LEFT OUTER JOIN
{{ source('shared', 'udm_address_labels_new')}} as tx_from_labels
ON e.tx_from = tx_from_labels.address AND tx_from_labels.blockchain = 'algorand'

LEFT OUTER JOIN
{{ source('shared', 'udm_address_labels_new')}} as tx_to_labels
ON e.tx_to = tx_to_labels.address AND tx_to_labels.blockchain = 'algorand'

LEFT OUTER JOIN
{{ source('shared', 'udm_address_labels_new')}} as event_from_labels
ON e.event_from = event_from_labels.address AND event_from_labels.blockchain = 'algorand'

LEFT OUTER JOIN
{{ source('shared', 'udm_address_labels_new')}} as event_to_labels
ON e.event_to = event_to_labels.address AND event_to_labels.blockchain = 'algorand'

LEFT OUTER JOIN
{{ source('shared', 'udm_decimal_adjustments')}} adj
ON e.event_currency = adj.token_identifier AND adj.blockchain = 'algorand'
-- ON e.blockchain = adj.blockchain AND adj.blockchain = 'algorand'

LEFT OUTER JOIN prices
ON prices.hour = date_trunc('hour', e.block_timestamp)
AND prices.symbol = e.event_currency

LEFT OUTER JOIN tx_asset_type
ON e.tx_id = tx_asset_type.tx_id_asset

WHERE
{% if is_incremental() %}
block_timestamp >= getdate() - interval '7 days'
{% else %}
block_timestamp >= getdate() - interval '9 months'
{% endif %}
9 changes: 8 additions & 1 deletion models/sources.yml
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,7 @@ sources:
- name: udm_balances
- name: udm_decimal_adjustments
- name: udm_velocity
- name: udm_address_labels_new
- name: ethereum
schema: silver
tables:
Expand Down Expand Up @@ -54,4 +55,10 @@ sources:
- name: ethereum_nondbt
schema: ethereum
tables:
- name: token_prices_hourly_v2
- name: token_prices_hourly_v2
- name: algorand
schema: silver
tables:
- name: udm_daily_balances_algorand
- name: udm_events_algorand
- name: udm_transfers_algorand