-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Refactor payment models and switch to incremental
Deleted `dbt_payment_total.sql` and added `dbt_all_payments.sql` for optimized query performance. Updated other models (`dbt_mint_per_month.sql`, `dbt_payment_per_month.sql`, `dbt_fleet_split_payments.sql`) to use `dbt_all_payments.sql` and made them incremental. Added indexing and streamlined payment data aggregation.
- Loading branch information
Showing
6 changed files
with
139 additions
and
104 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,114 @@ | ||
{{ | ||
config( | ||
materialized='incremental', | ||
indexes=[ | ||
{'columns': ['type']}, | ||
{'columns': ['block_number']}, | ||
{'columns': ['timestamp']}, | ||
{'columns': ['payee_address']}, | ||
] | ||
) | ||
}} | ||
|
||
select 'regular' as type, | ||
m.amount as regular_payment, | ||
0 as ai_payment, | ||
0 as map_consumption_reward, | ||
0 as operational_payment, | ||
0 as fleet_payment, | ||
b.timestamp, | ||
b.number as block_number, | ||
t.hash as trx_hash, | ||
m.to_address payee_address, | ||
false as is_fleet | ||
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 | ||
{% if is_incremental() %} | ||
where b.number > (select coalesce(max(block_number), 0) from "hivemapper"."hivemapper"."dbt_all_payments" where type = 'regular') | ||
{% 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, | ||
b.timestamp, | ||
b.number as block_number, | ||
t.hash as trx_hash, | ||
m.to_address payee_address, | ||
false as is_fleet | ||
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 | ||
{% if is_incremental() %} | ||
where b.number > (select coalesce(max(block_number), 0) from "hivemapper"."hivemapper"."dbt_all_payments" where type = 'ai_payments') | ||
{% 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, | ||
b.timestamp, | ||
b.number as block_number, | ||
t.hash as trx_hash, | ||
m.to_address payee_address, | ||
false as is_fleet | ||
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 | ||
{% if is_incremental() %} | ||
where b.number > (select coalesce(max(block_number), 0) from "hivemapper"."hivemapper"."dbt_all_payments" where type = 'map_consumption_reward') | ||
{% 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, | ||
b.timestamp, | ||
b.number as block_number, | ||
t.hash as trx_hash, | ||
m.to_address payee_address, | ||
false as is_fleet | ||
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 | ||
{% if is_incremental() %} | ||
where b.number > (select coalesce(max(block_number), 0) from "hivemapper"."hivemapper"."dbt_all_payments" where type = 'operational_payments') | ||
{% 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, | ||
b.timestamp, | ||
b.number as block_number, | ||
t.hash as trx_hash, | ||
m.to_address payee_address, | ||
p.fleet_mint_id = m.id as is_fleet | ||
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 | ||
{% if is_incremental() %} | ||
where b.number > (select coalesce(max(block_number), 0) from "hivemapper"."hivemapper"."dbt_all_payments" where type = 'fleet_payments') | ||
{% endif %} |
20 changes: 11 additions & 9 deletions
20
dbt/hivemapper/models/example/dbt_fleet_split_payments.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,13 +1,15 @@ | ||
{{ config(materialized='table') }} | ||
|
||
select * from ( | ||
select 'fleet' as metric, sum(mints.amount) payment | ||
from hivemapper.split_payments | ||
inner join hivemapper.mints mints on mints.id = split_payments.fleet_mint_id | ||
select * | ||
from (select 'fleet' as metric, sum(fleet_payment) payment | ||
from hivemapper.dbt_all_payments p | ||
where p.type = 'fleet_payments' | ||
and p.is_fleet = true | ||
|
||
union | ||
union | ||
|
||
select 'driver' as metric, sum(fleet_payment) payment | ||
from hivemapper.dbt_all_payments p | ||
where p.type = 'fleet_payments' | ||
and p.is_fleet = false) as metrics | ||
|
||
select 'driver' as metric, sum(mints.amount) payment | ||
from hivemapper.split_payments | ||
inner join hivemapper.mints mints on mints.id = split_payments.driver_mint_id | ||
) as metrics |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,7 +1,11 @@ | ||
{{ config(materialized='table') }} | ||
{{ config(materialized='incremental') }} | ||
|
||
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) |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,63 +1,11 @@ | ||
{{ config(materialized='table') }} | ||
|
||
-- select DATE_TRUNC('month', b.timestamp) as month, sum(m.amount) as total | ||
-- from hivemapper.payments p | ||
-- inner join hivemapper.mints m on m.id = p.mint_id | ||
-- inner join hivemapper.transactions t on t.id = m.transaction_id | ||
-- inner join hivemapper.blocks b on b.id = t.block_id | ||
-- group by DATE_TRUNC('month', b.timestamp) | ||
|
||
|
||
select | ||
payment.month as month, | ||
COALESCE(payment.total,0) driver_payment, | ||
COALESCE(ai_payment.total,0) as ai_payment, | ||
COALESCE(map_consumption_reward.total,0) as map_consumption_reward, | ||
COALESCE(operational_payments.total,0) as operational_payments, | ||
COALESCE(split_payments.total,0) as split_payments, | ||
COALESCE(payment.total, 0) + COALESCE(ai_payment.total, 0) + COALESCE(map_consumption_reward.total, 0) + COALESCE(operational_payments.total, 0) + COALESCE(split_payments.total, 0) as total from | ||
|
||
(select DATE_TRUNC('month', b.timestamp) as month, sum(m.amount) as total | ||
from hivemapper.payments p | ||
inner join hivemapper.mints m on m.id = p.mint_id | ||
inner join hivemapper.transactions t on t.id = m.transaction_id | ||
inner join hivemapper.blocks b on b.id = t.block_id | ||
group by DATE_TRUNC('month', b.timestamp)) payment | ||
|
||
LEFT JOIN | ||
|
||
(select DATE_TRUNC('month', b.timestamp) as month, sum(m.amount) as total | ||
from hivemapper.ai_payments p | ||
inner join hivemapper.mints m on m.id = p.mint_id | ||
inner join hivemapper.transactions t on t.id = m.transaction_id | ||
inner join hivemapper.blocks b on b.id = t.block_id | ||
group by DATE_TRUNC('month', b.timestamp)) ai_payment on payment.month = ai_payment.month | ||
|
||
LEFT JOIN | ||
|
||
(select DATE_TRUNC('month', b.timestamp) as month, sum(m.amount) as total | ||
from hivemapper.map_consumption_reward p | ||
inner join hivemapper.mints m on m.id = p.mint_id | ||
inner join hivemapper.transactions t on t.id = m.transaction_id | ||
inner join hivemapper.blocks b on b.id = t.block_id | ||
group by DATE_TRUNC('month', b.timestamp)) map_consumption_reward on payment.month = map_consumption_reward.month | ||
|
||
LEFT JOIN | ||
|
||
(select DATE_TRUNC('month', b.timestamp) as month, sum(m.amount) as total | ||
from hivemapper.operational_payments p | ||
inner join hivemapper.mints m on m.id = p.mint_id | ||
inner join hivemapper.transactions t on t.id = m.transaction_id | ||
inner join hivemapper.blocks b on b.id = t.block_id | ||
group by DATE_TRUNC('month', b.timestamp)) operational_payments on payment.month = operational_payments.month | ||
|
||
LEFT JOIN | ||
|
||
(select DATE_TRUNC('month', b.timestamp) as month, sum(m.amount) as total | ||
from hivemapper.split_payments p | ||
inner join hivemapper.mints m on m.id = p.fleet_mint_id or m.id = p.driver_mint_id | ||
inner join hivemapper.transactions t on t.id = m.transaction_id | ||
inner join hivemapper.blocks b on b.id = t.block_id | ||
group by DATE_TRUNC('month', b.timestamp)) split_payments on payment.month = split_payments.month | ||
|
||
order by payment.month | ||
DATE_TRUNC('month', p.timestamp) as month, | ||
sum(p.regular_payment) as regular, | ||
sum(p.ai_payment) as ai, | ||
sum(p.map_consumption_reward) as map_consumption, | ||
sum(p.operational_payment) as operational, | ||
sum(p.fleet_payment) as fleet | ||
from hivemapper.dbt_all_payments p | ||
group by DATE_TRUNC('month', p.timestamp) |
This file was deleted.
Oops, something went wrong.