From 6c440e1c2b7e3f32219e14c9cb7b0cabae5bcebe Mon Sep 17 00:00:00 2001 From: Ian Whitestone Date: Sat, 3 Jun 2023 20:02:52 -0400 Subject: [PATCH] Daily rates improvements (#114) * Daily rates improvements * Release 4.2.1 --- .changes/4.2.1.md | 7 ++ CHANGELOG.md | 8 ++ dbt_project.yml | 2 +- .../seeds/monthly_spend_fixture.csv | 6 ++ models/cost_per_query.sql | 8 +- models/daily_rates.sql | 52 ++++++++--- models/daily_spend.sql | 91 +++---------------- ...ng_balance_daily_without_contract_view.sql | 16 ++++ 8 files changed, 94 insertions(+), 96 deletions(-) create mode 100644 .changes/4.2.1.md create mode 100644 models/remaining_balance_daily_without_contract_view.sql diff --git a/.changes/4.2.1.md b/.changes/4.2.1.md new file mode 100644 index 0000000..6776884 --- /dev/null +++ b/.changes/4.2.1.md @@ -0,0 +1,7 @@ +## dbt-snowflake-monitoring 4.2.1 - June 03, 2023 + +### Fixes + +- Daily rates improvements ([#114](https://github.com/get-select/dbt-snowflake-monitoring/pull/114)) + + diff --git a/CHANGELOG.md b/CHANGELOG.md index 2ad7205..e4f0100 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -5,6 +5,14 @@ The format is based on [Keep a Changelog](https://keepachangelog.com/en/1.0.0/), adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0.html), and is generated by [Changie](https://github.com/miniscruff/changie). +## dbt-snowflake-monitoring 4.2.1 - June 03, 2023 + +### Fixes + +- Daily rates improvements ([#114](https://github.com/get-select/dbt-snowflake-monitoring/pull/114)) + + + ## dbt-snowflake-monitoring 4.2.0 - May 27, 2023 ### Features diff --git a/dbt_project.yml b/dbt_project.yml index 173e4c9..85f0309 100644 --- a/dbt_project.yml +++ b/dbt_project.yml @@ -1,5 +1,5 @@ name: 'dbt_snowflake_monitoring' -version: '4.2.0' +version: '4.3.0' config-version: 2 profile: dbt_snowflake_monitoring diff --git a/integration_test_project/seeds/monthly_spend_fixture.csv b/integration_test_project/seeds/monthly_spend_fixture.csv index 36d2999..018b7b6 100644 --- a/integration_test_project/seeds/monthly_spend_fixture.csv +++ b/integration_test_project/seeds/monthly_spend_fixture.csv @@ -4,3 +4,9 @@ MONTH,SERVICE,SPEND 2022-04-01,Adj For Incl Cloud Services,-74.921528302 2022-04-01,Cloud Services,74.921528302 2022-04-01,Automatic Clustering,0.051113362 +2022-04-01,Snowpipe,0 +2022-04-01,Serverless Tasks,0 +2022-04-01,Search Optimization,0 +2022-04-01,Replication,0 +2022-04-01,Query Acceleration,0 +2022-04-01,Materialized Views,0 diff --git a/models/cost_per_query.sql b/models/cost_per_query.sql index 80d6078..eec7622 100644 --- a/models/cost_per_query.sql +++ b/models/cost_per_query.sql @@ -73,19 +73,15 @@ query_cost as ( select query_seconds_per_hour.*, credits_billed_hourly.credits_used_compute * daily_rates.effective_rate as actual_warehouse_cost, - credits_billed_hourly.credits_used_compute * query_seconds_per_hour.fraction_of_total_query_time_in_hour * coalesce(daily_rates.effective_rate, current_rates.effective_rate) as allocated_compute_cost_in_hour + credits_billed_hourly.credits_used_compute * query_seconds_per_hour.fraction_of_total_query_time_in_hour * daily_rates.effective_rate as allocated_compute_cost_in_hour from query_seconds_per_hour inner join credits_billed_hourly on query_seconds_per_hour.warehouse_id = credits_billed_hourly.warehouse_id and query_seconds_per_hour.hour = credits_billed_hourly.hour - left join {{ ref('daily_rates') }} + inner join {{ ref('daily_rates') }} on date(query_seconds_per_hour.start_time) = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'compute' - inner join {{ ref('daily_rates') }} as current_rates - on current_rates.is_latest_rate - and current_rates.service_type = 'COMPUTE' - and current_rates.usage_type = 'compute' ), cost_per_query as ( diff --git a/models/daily_rates.sql b/models/daily_rates.sql index 06d3226..cdb17d3 100644 --- a/models/daily_rates.sql +++ b/models/daily_rates.sql @@ -27,7 +27,7 @@ dates_base as ( from table(generator(rowcount => (365 * 3))) ), -rate_sheet_daily as ( +rate_sheet_daily_base as ( select date, usage_type, @@ -39,27 +39,53 @@ rate_sheet_daily as ( account_locator = {{ account_locator }} ), +stop_thresholds as ( + select min(date) as start_date + from rate_sheet_daily_base + + union all + + select min(date) as start_date + from {{ ref('remaining_balance_daily_without_contract_view') }} +), + +date_range as ( + select + max(start_date) as start_date, + current_date as end_date + from stop_thresholds +), + remaining_balance_daily as ( select date, free_usage_balance + capacity_balance + on_demand_consumption_balance + rollover_balance as remaining_balance, remaining_balance < 0 as is_account_in_overage - from {{ ref('stg_remaining_balance_daily') }} + from {{ ref('remaining_balance_daily_without_contract_view') }} ), -rates_date_range as ( +latest_remaining_balance_daily as ( select - min(date) as start_date, - max(date) as end_date - from rate_sheet_daily + date, + remaining_balance, + is_account_in_overage + from remaining_balance_daily + qualify row_number() over (order by date desc) = 1 +), + +rate_sheet_daily as ( + select rate_sheet_daily_base.* + from rate_sheet_daily_base + inner join date_range + on rate_sheet_daily_base.date between date_range.start_date and date_range.end_date ), rates_date_range_w_usage_types as ( select - rates_date_range.start_date, - rates_date_range.end_date, + date_range.start_date, + date_range.end_date, usage_types.usage_type - from rates_date_range + from date_range cross join (select distinct usage_type from rate_sheet_daily) as usage_types ), @@ -93,14 +119,16 @@ rates_w_overage as ( ) as currency, base.usage_type like 'overage-%' as is_overage_rate, replace(base.usage_type, 'overage-', '') as associated_usage_type, + coalesce(remaining_balance_daily.is_account_in_overage, latest_remaining_balance_daily.is_account_in_overage) as _is_account_in_overage, case - when remaining_balance_daily.is_account_in_overage and is_overage_rate then 1 - when not remaining_balance_daily.is_account_in_overage and not is_overage_rate then 1 + when _is_account_in_overage and is_overage_rate then 1 + when not _is_account_in_overage and not is_overage_rate then 1 else 0 end as rate_priority from base - inner join remaining_balance_daily + inner join latest_remaining_balance_daily + left join remaining_balance_daily on base.date = remaining_balance_daily.date left join rate_sheet_daily on base.date = rate_sheet_daily.date diff --git a/models/daily_spend.sql b/models/daily_spend.sql index c632020..5a23a9d 100644 --- a/models/daily_spend.sql +++ b/models/daily_spend.sql @@ -32,12 +32,6 @@ dates as ( ) ), -latest_rates as ( - select * - from {{ ref('daily_rates') }} - where is_latest_rate -), - storage_terabytes_daily as ( select date, @@ -76,14 +70,12 @@ storage_spend_daily as ( div0( storage_terabytes_daily.storage_terabytes, dates.days_in_month - ) * coalesce( - daily_rates.effective_rate, latest_rates.effective_rate - ) + ) * daily_rates.effective_rate ), 0 ) as spend, spend as spend_net_cloud_services, - any_value(coalesce(daily_rates.currency, latest_rates.currency)) as currency + any_value(daily_rates.currency) as currency from dates left join storage_terabytes_daily on dates.date = storage_terabytes_daily.date @@ -91,9 +83,6 @@ storage_spend_daily as ( on storage_terabytes_daily.date = daily_rates.date and daily_rates.service_type = 'STORAGE' and daily_rates.usage_type = 'storage' - inner join latest_rates - on latest_rates.service_type = 'STORAGE' - and latest_rates.usage_type = 'storage' group by 1, 2, 3, 4, 5 ), @@ -106,9 +95,7 @@ compute_spend_daily as ( null as database_name, coalesce( sum( - stg_metering_history.credits_used_compute * coalesce( - daily_rates.effective_rate, latest_rates.effective_rate - ) + stg_metering_history.credits_used_compute * daily_rates.effective_rate ), 0 ) as spend, @@ -123,9 +110,6 @@ compute_spend_daily as ( on dates.date = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'compute' - inner join latest_rates - on latest_rates.service_type = 'COMPUTE' - and latest_rates.usage_type = 'compute' where stg_metering_history.service_type = 'WAREHOUSE_METERING' and stg_metering_history.name != 'CLOUD_SERVICES_ONLY' group by 1, 2, 3, 4 @@ -140,9 +124,7 @@ serverless_task_spend_daily as ( stg_serverless_task_history.database_name, coalesce( sum( - stg_serverless_task_history.credits_used * coalesce( - daily_rates.effective_rate, latest_rates.effective_rate - ) + stg_serverless_task_history.credits_used * daily_rates.effective_rate ), 0 ) as spend, @@ -157,9 +139,6 @@ serverless_task_spend_daily as ( on dates.date = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'serverless tasks' - inner join latest_rates - on latest_rates.service_type = 'COMPUTE' - and latest_rates.usage_type = 'serverless tasks' group by 1, 2, 3, 4, 5 ), @@ -172,9 +151,7 @@ adj_for_incl_cloud_services_daily as ( null as database_name, coalesce( sum( - stg_metering_daily_history.credits_adjustment_cloud_services * coalesce( - daily_rates.effective_rate, latest_rates.effective_rate - ) + stg_metering_daily_history.credits_adjustment_cloud_services * daily_rates.effective_rate ), 0 ) as spend, @@ -187,9 +164,6 @@ adj_for_incl_cloud_services_daily as ( on dates.date = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'cloud services' - inner join latest_rates - on latest_rates.service_type = 'COMPUTE' - and latest_rates.usage_type = 'cloud services' group by 1, 2, 3, 4 ), @@ -207,12 +181,8 @@ _cloud_services_spend_daily as ( coalesce( sum(stg_metering_history.credits_used_cloud_services), 0 ) as credits_used_cloud_services, - any_value( - coalesce(daily_rates.effective_rate, latest_rates.effective_rate) - ) as effective_rate, - any_value( - coalesce(daily_rates.currency, latest_rates.currency) - ) as currency + any_value(daily_rates.effective_rate) as effective_rate, + any_value(daily_rates.currency) as currency from dates left join {{ ref('stg_metering_history') }} on dates.date = convert_timezone( @@ -223,9 +193,6 @@ _cloud_services_spend_daily as ( on dates.date = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'cloud services' - inner join latest_rates - on latest_rates.service_type = 'COMPUTE' - and latest_rates.usage_type = 'cloud services' group by 1, 2, 3, 4 ), @@ -257,7 +224,7 @@ cloud_services_spend_daily as ( credits_billed_daily.daily_credits_used_cloud_services ) * credits_billed_daily.daily_billable_cloud_services ) * _cloud_services_spend_daily.effective_rate as spend_net_cloud_services, - currency as currency + _cloud_services_spend_daily.currency from _cloud_services_spend_daily inner join credits_billed_daily on _cloud_services_spend_daily.date = credits_billed_daily.date @@ -273,9 +240,7 @@ automatic_clustering_spend_daily as ( null as database_name, coalesce( sum( - stg_metering_history.credits_used * coalesce( - daily_rates.effective_rate, latest_rates.effective_rate - ) + stg_metering_history.credits_used * daily_rates.effective_rate ), 0 ) as spend, @@ -291,9 +256,6 @@ automatic_clustering_spend_daily as ( on dates.date = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'automatic clustering' - inner join latest_rates - on latest_rates.service_type = 'COMPUTE' - and latest_rates.usage_type = 'automatic clustering' group by 1, 2, 3, 4 ), @@ -306,9 +268,7 @@ materialized_view_spend_daily as ( null as database_name, coalesce( sum( - stg_metering_history.credits_used * coalesce( - daily_rates.effective_rate, latest_rates.effective_rate - ) + stg_metering_history.credits_used * daily_rates.effective_rate ), 0 ) as spend, @@ -324,9 +284,6 @@ materialized_view_spend_daily as ( on dates.date = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'materialized view' {# TODO: need someone to confirm whether its materialized 'view' or 'views' #} - inner join latest_rates - on latest_rates.service_type = 'COMPUTE' - and latest_rates.usage_type = 'materialized view' group by 1, 2, 3, 4 ), @@ -339,9 +296,7 @@ snowpipe_spend_daily as ( null as database_name, coalesce( sum( - stg_metering_history.credits_used * coalesce( - daily_rates.effective_rate, latest_rates.effective_rate - ) + stg_metering_history.credits_used * daily_rates.effective_rate ), 0 ) as spend, @@ -357,9 +312,6 @@ snowpipe_spend_daily as ( on dates.date = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'snowpipe' - inner join latest_rates - on latest_rates.service_type = 'COMPUTE' - and latest_rates.usage_type = 'snowpipe' group by 1, 2, 3, 4 ), @@ -372,9 +324,7 @@ query_acceleration_spend_daily as ( null as database_name, coalesce( sum( - stg_metering_history.credits_used * coalesce( - daily_rates.effective_rate, latest_rates.effective_rate - ) + stg_metering_history.credits_used * daily_rates.effective_rate ), 0 ) as spend, @@ -390,9 +340,6 @@ query_acceleration_spend_daily as ( on dates.date = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'query acceleration' - inner join latest_rates - on latest_rates.service_type = 'COMPUTE' - and latest_rates.usage_type = 'query acceleration' group by 1, 2, 3, 4 ), @@ -405,9 +352,7 @@ replication_spend_daily as ( null as database_name, coalesce( sum( - stg_metering_history.credits_used * coalesce( - daily_rates.effective_rate, latest_rates.effective_rate - ) + stg_metering_history.credits_used * daily_rates.effective_rate ), 0 ) as spend, @@ -423,9 +368,6 @@ replication_spend_daily as ( on dates.date = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'replication' - inner join latest_rates - on latest_rates.service_type = 'COMPUTE' - and latest_rates.usage_type = 'replication' group by 1, 2, 3, 4 ), @@ -438,9 +380,7 @@ search_optimization_spend_daily as ( null as database_name, coalesce( sum( - stg_metering_history.credits_used * coalesce( - daily_rates.effective_rate, latest_rates.effective_rate - ) + stg_metering_history.credits_used * daily_rates.effective_rate ), 0 ) as spend, @@ -456,9 +396,6 @@ search_optimization_spend_daily as ( on dates.date = daily_rates.date and daily_rates.service_type = 'COMPUTE' and daily_rates.usage_type = 'search optimization' - inner join latest_rates - on latest_rates.service_type = 'COMPUTE' - and latest_rates.usage_type = 'search optimization' group by 1, 2, 3, 4 ) diff --git a/models/remaining_balance_daily_without_contract_view.sql b/models/remaining_balance_daily_without_contract_view.sql new file mode 100644 index 0000000..e03a1de --- /dev/null +++ b/models/remaining_balance_daily_without_contract_view.sql @@ -0,0 +1,16 @@ +select + date, + organization_name, + currency, + free_usage_balance, + capacity_balance, + on_demand_consumption_balance, + rollover_balance +from {{ ref('stg_remaining_balance_daily') }} +{# + From what I can tell, there will only ever be 1 organization_name in remaining_balance_daily. + During a contract switchover, there may be two records with the same date, but different contract_numbers. + Assume the higher contract_number is more recent. Chose not to group by date and aggregate balances in + case the currency changes.. +#} +qualify row_number() over (partition by date order by contract_number desc) = 1