From cfb40abf518fa48abab47ad79e3344c23e279e0a Mon Sep 17 00:00:00 2001 From: Carl Cervone <42869436+ccerv1@users.noreply.github.com> Date: Tue, 3 Dec 2024 19:12:08 -0500 Subject: [PATCH] refactor(dbt): gitcoin models to include round uids (#2577) --- .../funding/int_gitcoin_funding_events.sql | 45 +++++++++++++++- .../funding/int_gitcoin_funding_rounds.sql | 51 ++++++------------ .../funding/int_gitcoin_project_directory.sql | 52 +++++++++++-------- .../int_oss_funding_grants_to_project.sql | 2 +- .../gitcoin_funding_events_by_project_v0.sql | 3 +- .../gitcoin/gitcoin_funding_rounds_v0.sql | 11 ++++ .../gitcoin/gitcoin_project_directory_v0.sql | 10 ++++ 7 files changed, 113 insertions(+), 61 deletions(-) create mode 100644 warehouse/dbt/models/marts/gitcoin/gitcoin_funding_rounds_v0.sql create mode 100644 warehouse/dbt/models/marts/gitcoin/gitcoin_project_directory_v0.sql diff --git a/warehouse/dbt/models/intermediate/funding/int_gitcoin_funding_events.sql b/warehouse/dbt/models/intermediate/funding/int_gitcoin_funding_events.sql index ddb242fef..62da2fdfe 100644 --- a/warehouse/dbt/models/intermediate/funding/int_gitcoin_funding_events.sql +++ b/warehouse/dbt/models/intermediate/funding/int_gitcoin_funding_events.sql @@ -4,7 +4,7 @@ with unioned_funding_events as ( select * from {{ ref('stg_gitcoin__matching') }} ), -labeled_funding_events as ( +funding_events_with_round_types as ( select *, case @@ -35,6 +35,48 @@ labeled_funding_events as ( from unioned_funding_events ), +labeled_funding_events as ( + select + *, + case + when round_type = 'DirectDonations' + then 'CGrants - Direct' + when round_type = 'MainRound' and round_number between 1 and 15 + then main_round_label + when ( + round_type = 'MainRound' and round_number = 16 + and ( + gitcoin_round_id = 'alpha-climate' + or round_name = 'Climate Solutions' + ) + ) then 'GG-16 (Climate Solutions)' + when ( + round_type = 'MainRound' and round_number = 16 + and ( + gitcoin_round_id = 'alpha-eth-infra' + or round_name = 'Ethereum Infrastructure' + ) + ) then 'GG-16 (Ethereum Infrastructure)' + when ( + round_type = 'MainRound' and round_number = 16 + and ( + gitcoin_round_id = 'alpha-oss' + or round_name = 'Open Source Software' + ) + ) then 'GG-16 (Open Source Software)' + when ( + round_type = 'MainRound' and round_number > 16 + ) then concat(main_round_label, ' - ', cast(gitcoin_round_id as string)) + when round_type = 'PartnerRound' + then concat( + round_type, ' - ', + cast(chain_id as string), ' - ', + gitcoin_round_id + ) + end as oso_generated_round_label + from funding_events_with_round_types +), + joined_events as ( select labeled_funding_events.*, @@ -58,6 +100,7 @@ select main_round_label, round_name, chain_id, + oso_generated_round_label, gitcoin_project_id, project_application_title, oso_project_id, diff --git a/warehouse/dbt/models/intermediate/funding/int_gitcoin_funding_rounds.sql b/warehouse/dbt/models/intermediate/funding/int_gitcoin_funding_rounds.sql index 14ab64a33..ca4be6c8a 100644 --- a/warehouse/dbt/models/intermediate/funding/int_gitcoin_funding_rounds.sql +++ b/warehouse/dbt/models/intermediate/funding/int_gitcoin_funding_rounds.sql @@ -1,42 +1,21 @@ -with partner_rounds as ( - select * - from {{ ref('int_gitcoin_funding_events') }} - where - round_type = 'PartnerRound' - and round_name is not null -), - -main_rounds as ( - select * - from {{ ref('int_gitcoin_funding_events') }} - where round_type = 'MainRound' -), - -unioned as ( - select * from partner_rounds - union all - select * from main_rounds -) - select - gitcoin_data_source, - gitcoin_round_id, - round_number, - round_name, + oso_generated_round_label, round_type, main_round_label, - array_agg(distinct chain_id) as chain_ids, - sum(amount_in_usd) as total_amount_in_usd, - count(distinct gitcoin_project_id) as count_projects -from unioned + min(event_time) as first_event_time, + max(event_time) as last_event_time, + count(distinct gitcoin_project_id) as count_projects, + count(distinct donor_address) as unique_donors, + sum( + case + when gitcoin_data_source = 'MatchFunding' then amount_in_usd + else 0 + end + ) as match_funding_amount_in_usd, + sum(amount_in_usd) as total_funding_amount_in_usd +from {{ ref('int_gitcoin_funding_events') }} group by - gitcoin_data_source, - gitcoin_round_id, - round_number, - round_name, + oso_generated_round_label, round_type, main_round_label -order by - round_type asc, - main_round_label desc, - gitcoin_round_id asc +order by oso_generated_round_label diff --git a/warehouse/dbt/models/intermediate/funding/int_gitcoin_project_directory.sql b/warehouse/dbt/models/intermediate/funding/int_gitcoin_project_directory.sql index 2b06843de..211b1fa81 100644 --- a/warehouse/dbt/models/intermediate/funding/int_gitcoin_project_directory.sql +++ b/warehouse/dbt/models/intermediate/funding/int_gitcoin_project_directory.sql @@ -2,16 +2,16 @@ with gitcoin_projects as ( select distinct pg.latest_project_github, pg.latest_project_recipient_address, - project_lookup.gitcoin_project_id + project_lookup.gitcoin_project_id, + not( + not regexp_contains(pg.latest_project_github, '^[a-zA-Z0-9_-]+$') + or pg.latest_project_github like '%?%' + or pg.latest_project_github = 'none' + or length(pg.latest_project_github) > 39 + ) as is_valid_github from {{ ref('stg_gitcoin__project_groups') }} as pg left join {{ ref('stg_gitcoin__project_lookup') }} as project_lookup on pg.gitcoin_group_id = project_lookup.gitcoin_group_id - where not ( - not regexp_contains(pg.latest_project_github, '^[a-zA-Z0-9_-]+$') - or pg.latest_project_github like '%?%' - or pg.latest_project_github = 'none' - or length(pg.latest_project_github) > 39 - ) ), oso_projects as ( @@ -49,27 +49,35 @@ repo_matches as ( final_matches as ( select distinct - gitcoin_project_id, - latest_project_github, - latest_project_recipient_address, - oso_wallet_match, - oso_repo_match, + gitcoin_projects.gitcoin_project_id, + gitcoin_projects.latest_project_github, + gitcoin_projects.latest_project_recipient_address, + repo_matches.oso_wallet_match, + repo_matches.oso_repo_match, case - when oso_wallet_match is not null then oso_wallet_match - when oso_repo_match is not null then oso_repo_match + when repo_matches.oso_wallet_match is not null + then repo_matches.oso_wallet_match + when + repo_matches.oso_repo_match is not null + and gitcoin_projects.is_valid_github + then repo_matches.oso_repo_match end as oso_project_id from repo_matches + left join gitcoin_projects + on repo_matches.gitcoin_project_id = gitcoin_projects.gitcoin_project_id ) select - final_matches.gitcoin_project_id, - final_matches.latest_project_github, - final_matches.latest_project_recipient_address, - final_matches.oso_wallet_match, - final_matches.oso_repo_match, - final_matches.oso_project_id, + gp.gitcoin_project_id, + gp.latest_project_github, + gp.latest_project_recipient_address, + fm.oso_wallet_match, + fm.oso_repo_match, + fm.oso_project_id, projects.project_name as oso_project_name, projects.display_name as oso_display_name -from final_matches +from gitcoin_projects as gp +left join final_matches as fm + on gp.gitcoin_project_id = fm.gitcoin_project_id left join {{ ref('projects_v1') }} as projects - on final_matches.oso_project_id = projects.project_id + on fm.oso_project_id = projects.project_id diff --git a/warehouse/dbt/models/intermediate/funding/int_oss_funding_grants_to_project.sql b/warehouse/dbt/models/intermediate/funding/int_oss_funding_grants_to_project.sql index 88491bf51..ceab7f289 100644 --- a/warehouse/dbt/models/intermediate/funding/int_oss_funding_grants_to_project.sql +++ b/warehouse/dbt/models/intermediate/funding/int_oss_funding_grants_to_project.sql @@ -28,7 +28,7 @@ gitcoin_data as ( transaction_hash, cast(gitcoin_project_id as string) ) as event_source_id, - concat('GITCOIN', '_', upper(gitcoin_data_source)) as event_source, + concat('GITCOIN', '_', upper(oso_generated_round_label)) as event_source, oso_project_name as to_project_name, 'gitcoin' as from_project_name, amount_in_usd as amount diff --git a/warehouse/dbt/models/marts/gitcoin/gitcoin_funding_events_by_project_v0.sql b/warehouse/dbt/models/marts/gitcoin/gitcoin_funding_events_by_project_v0.sql index c5a60fd11..c33ea1902 100644 --- a/warehouse/dbt/models/marts/gitcoin/gitcoin_funding_events_by_project_v0.sql +++ b/warehouse/dbt/models/marts/gitcoin/gitcoin_funding_events_by_project_v0.sql @@ -6,6 +6,7 @@ select round_type, main_round_label, round_name, + oso_generated_round_label, gitcoin_project_id, project_application_title, oso_project_id, @@ -14,7 +15,6 @@ select donor_address, sum(amount_in_usd) as amount_in_usd from {{ ref('int_gitcoin_funding_events') }} -where oso_project_id is not null group by event_time, gitcoin_data_source, @@ -23,6 +23,7 @@ group by round_type, main_round_label, round_name, + oso_generated_round_label, gitcoin_project_id, project_application_title, oso_project_id, diff --git a/warehouse/dbt/models/marts/gitcoin/gitcoin_funding_rounds_v0.sql b/warehouse/dbt/models/marts/gitcoin/gitcoin_funding_rounds_v0.sql new file mode 100644 index 000000000..eebf2cce1 --- /dev/null +++ b/warehouse/dbt/models/marts/gitcoin/gitcoin_funding_rounds_v0.sql @@ -0,0 +1,11 @@ +select + oso_generated_round_label, + round_type, + main_round_label, + count_projects, + unique_donors, + match_funding_amount_in_usd, + total_funding_amount_in_usd, + first_event_time, + last_event_time +from {{ ref('int_gitcoin_funding_rounds') }} diff --git a/warehouse/dbt/models/marts/gitcoin/gitcoin_project_directory_v0.sql b/warehouse/dbt/models/marts/gitcoin/gitcoin_project_directory_v0.sql new file mode 100644 index 000000000..54e4b201e --- /dev/null +++ b/warehouse/dbt/models/marts/gitcoin/gitcoin_project_directory_v0.sql @@ -0,0 +1,10 @@ +select distinct + gitcoin_project_id, + latest_project_github, + latest_project_recipient_address, + oso_wallet_match, + oso_repo_match, + oso_project_id, + oso_project_name, + oso_display_name +from {{ ref('int_gitcoin_project_directory') }}