Skip to content

Commit

Permalink
Update profiles, payment calculations and add new tables
Browse files Browse the repository at this point in the history
Updated the profiles.yml to use environment variables for passwords. Enhanced payment calculations to include USD equivalents by joining with the prices table. Added a new incremental table for mints and simplified the mint per month query. Added a basic index.html file with an iframe for embedding a dashboard.
  • Loading branch information
billettc committed Sep 13, 2024
1 parent 54cf0a1 commit c67cb6a
Show file tree
Hide file tree
Showing 5 changed files with 99 additions and 33 deletions.
20 changes: 20 additions & 0 deletions dbt/hivemapper/models/example/dbt_all_mints.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
{{
config(
materialized='incremental',
indexes=[
{'columns': ['block_number']},
{'columns': ['block_time']},
{'columns': ['trx_hash']},
{'columns': ['to_address']},
]
)
}}

select b.timestamp as block_time, m.amount, m.to_address, t.hash as trx_hash, b.number as block_number
from hivemapper.mints m
inner join hivemapper.transactions t on t.id = m.transaction_id
inner join hivemapper.blocks b on b.id = t.block_id
{% if is_incremental() %}
where b.number > (select max(block_number) from {{ this }})
and date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01') <= (select p.timestamp from "hivemapper"."hivemapper"."prices" p order by p.timestamp desc limit 1)
{% endif %}
77 changes: 56 additions & 21 deletions dbt/hivemapper/models/example/dbt_all_payments.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,18 +5,23 @@
{'columns': ['type']},
{'columns': ['block_number']},
{'columns': ['block_time']},
{'columns': ['transaction_hash']},
{'columns': ['trx_hash']},
{'columns': ['payee_address']},
]
)
}}

select 'regular' as type,
m.amount as regular_payment,
prices.price * m.amount as regular_usd_payment,
0 as ai_payment,
0 as ai_usd_payment,
0 as map_consumption_reward,
0 as map_consumption_usd_reward,
0 as operational_payment,
0 as operational_usd_payment,
0 as fleet_payment,
0 as fleet_usd_payment,
b.timestamp as block_time,
b.number as block_number,
t.hash as trx_hash,
Expand All @@ -26,18 +31,25 @@ from hivemapper.blocks b
inner join hivemapper.transactions t on t.block_id = b.id
inner join hivemapper.mints m on m.transaction_id = t.id
inner join hivemapper.payments p on p.mint_id = m.id
inner join hivemapper.prices prices on prices.timestamp = date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01')
{% if is_incremental() %}
where b.number > (select coalesce(max(block_number), 0) from "hivemapper"."hivemapper"."dbt_all_payments" where type = 'regular')
and date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01') <= (select p.timestamp from "hivemapper"."hivemapper"."prices" p order by p.timestamp desc limit 1)
{% endif %}

union all

select 'ai_payments' as type,
0 as regular_payment,
m.amount as ai_payment,
0 as map_consumption_reward,
0 as operational_payment,
0 as fleet_payment,
0 as regular_payment,
0 as regular_usd_payment,
m.amount as ai_payment,
prices.price * m.amount as ai_usd_payment,
0 as map_consumption_reward,
0 as map_consumption_usd_reward,
0 as operational_payment,
0 as operational_usd_payment,
0 as fleet_payment,
0 as fleet_usd_payment,
b.timestamp as block_time,
b.number as block_number,
t.hash as trx_hash,
Expand All @@ -47,18 +59,25 @@ from hivemapper.blocks b
inner join hivemapper.transactions t on t.block_id = b.id
inner join hivemapper.mints m on m.transaction_id = t.id
inner join hivemapper.ai_payments p on p.mint_id = m.id
inner join hivemapper.prices prices on prices.timestamp = date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01')
{% if is_incremental() %}
where b.number > (select coalesce(max(block_number), 0) from "hivemapper"."hivemapper"."dbt_all_payments" where type = 'ai_payments')
and date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01') <= (select p.timestamp from "hivemapper"."hivemapper"."prices" p order by p.timestamp desc limit 1)
{% endif %}

union all

select 'map_consumption_reward' as type,
0 as regular_payment,
0 as ai_payment,
m.amount as map_consumption_reward,
0 as operational_payment,
0 as fleet_payment,
0 as regular_payment,
0 as regular_usd_payment,
0 as ai_payment,
0 as ai_usd_payment,
m.amount as map_consumption_reward,
prices.price * m.amount as map_consumption_usd_reward,
0 as operational_payment,
0 as operational_usd_payment,
0 as fleet_payment,
0 as fleet_usd_payment,
b.timestamp as block_time,
b.number as block_number,
t.hash as trx_hash,
Expand All @@ -68,18 +87,25 @@ from hivemapper.blocks b
inner join hivemapper.transactions t on t.block_id = b.id
inner join hivemapper.mints m on m.transaction_id = t.id
inner join hivemapper.map_consumption_reward p on p.mint_id = m.id
inner join hivemapper.prices prices on prices.timestamp = date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01')
{% if is_incremental() %}
where b.number > (select coalesce(max(block_number), 0) from "hivemapper"."hivemapper"."dbt_all_payments" where type = 'map_consumption_reward')
and date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01') <= (select p.timestamp from "hivemapper"."hivemapper"."prices" p order by p.timestamp desc limit 1)
{% endif %}

union all

select 'operational_payments' as type,
0 as regular_payment,
0 as ai_payment,
0 as map_consumption_reward,
m.amount as operational_payment,
0 as fleet_payment,
0 as regular_payment,
0 as regular_usd_payment,
0 as ai_payment,
0 as ai_usd_payment,
0 as map_consumption_reward,
0 as map_consumption_usd_reward,
m.amount as operational_payment,
prices.price * m.amount as operational_usd_payment,
0 as fleet_payment,
0 as fleet_usd_payment,
b.timestamp as block_time,
b.number as block_number,
t.hash as trx_hash,
Expand All @@ -89,18 +115,25 @@ from hivemapper.blocks b
inner join hivemapper.transactions t on t.block_id = b.id
inner join hivemapper.mints m on m.transaction_id = t.id
inner join hivemapper.operational_payments p on p.mint_id = m.id
inner join hivemapper.prices prices on prices.timestamp = date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01')
{% if is_incremental() %}
where b.number > (select coalesce(max(block_number), 0) from "hivemapper"."hivemapper"."dbt_all_payments" where type = 'operational_payments')
and date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01') <= (select p.timestamp from "hivemapper"."hivemapper"."prices" p order by p.timestamp desc limit 1)
{% endif %}

union all

select 'fleet_payments' as type,
0 as regular_payment,
0 as ai_payment,
0 as map_consumption_reward,
0 as operational_payment,
m.amount as fleet_payment,
0 as regular_payment,
0 as regular_usd_payment,
0 as ai_payment,
0 as ai_usd_payment,
0 as map_consumption_reward,
0 as map_consumption_usd_reward,
0 as operational_payment,
0 as operational_usd_payment,
m.amount as fleet_payment,
prices.price * m.amount as fleet_usd_payment,
b.timestamp as block_time,
b.number as block_number,
t.hash as trx_hash,
Expand All @@ -110,6 +143,8 @@ from hivemapper.blocks b
inner join hivemapper.transactions t on t.block_id = b.id
inner join hivemapper.mints m on m.transaction_id = t.id
inner join hivemapper.split_payments p on p.driver_mint_id = m.id or p.fleet_mint_id = m.id
inner join hivemapper.prices prices on prices.timestamp = date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01')
{% if is_incremental() %}
where b.number > (select coalesce(max(block_number), 0) from "hivemapper"."hivemapper"."dbt_all_payments" where type = 'fleet_payments')
and date_bin('5 minutes', b.timestamp , TIMESTAMP '2001-01-01') <= (select p.timestamp from "hivemapper"."hivemapper"."prices" p order by p.timestamp desc limit 1)
{% endif %}
16 changes: 6 additions & 10 deletions dbt/hivemapper/models/example/dbt_mint_per_month.sql
Original file line number Diff line number Diff line change
@@ -1,11 +1,7 @@
{{ config(materialized='incremental') }}
{{ config(materialized='table') }}

select DATE_TRUNC('month', b.timestamp) as month, COALESCE(SUM(br.amount), 0) as total
from hivemapper.mints br
inner join hivemapper.transactions t on t.id = br.transaction_id
inner join hivemapper.blocks b on b.id = t.block_id
{% if is_incremental() %}
where b.timestamp >= (select coalesce(max(month),'1900-01-01') from {{ this }} )
{% endif %}

group by DATE_TRUNC('month', b.timestamp)
select
DATE_TRUNC('month', p.block_time) as month,
sum(p.amount) as total
from hivemapper.dbt_all_mints p
group by DATE_TRUNC('month', p.block_time)
4 changes: 2 additions & 2 deletions dbt/hivemapper/profiles.yml
Original file line number Diff line number Diff line change
Expand Up @@ -4,15 +4,15 @@ hivemapper:
type: postgres
host: localhost
user: dev
password: SecureMe!
password: "{{ env_var('DBT_PASSWORD') }}"
port: 5433
dbname: hivemapper
schema: hivemapper
prod:
type: postgres
host: localhost
user: dev
password: SecureMe!
password: "{{ env_var('DBT_PASSWORD') }}"
port: 5433
dbname: hivemapper
schema: hivemapper
Expand Down
15 changes: 15 additions & 0 deletions web/index.html
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
<html>
<body>

<iframe
src="charless-macbook-pro-2.local:3000/public/dashboard/3e029abe-66bf-4cad-895c-e39922f03927?fleet_address="
frameborder="0"
width="800"
height="600"
allowtransparency
style="background: olive"
></iframe>

</body>

</html>

0 comments on commit c67cb6a

Please sign in to comment.