From 63440b50b243bbb3b01f85dc16befe7ff800f734 Mon Sep 17 00:00:00 2001 From: Ian Whitestone Date: Thu, 16 Feb 2023 21:22:15 -0500 Subject: [PATCH 1/4] Add spend_net_cloud_services --- models/daily_spend.sql | 62 ++++++++++++++++++++++++++++++++++-------- 1 file changed, 50 insertions(+), 12 deletions(-) diff --git a/models/daily_spend.sql b/models/daily_spend.sql index 19eaaba..14b1554 100644 --- a/models/daily_spend.sql +++ b/models/daily_spend.sql @@ -59,7 +59,8 @@ storage_spend_daily as ( storage_terabytes_daily.storage_type, null as warehouse_name, storage_terabytes_daily.database_name, - coalesce(sum(div0(storage_terabytes_daily.storage_terabytes, dates.days_in_month) * daily_rates.effective_rate), 0) as spend + coalesce(sum(div0(storage_terabytes_daily.storage_terabytes, dates.days_in_month) * daily_rates.effective_rate), 0) as spend, + spend as spend_net_cloud_services from dates left join storage_terabytes_daily on dates.date = storage_terabytes_daily.date inner join {{ ref('daily_rates') }} @@ -76,7 +77,8 @@ compute_spend_daily as ( null as storage_type, stg_metering_history.name as warehouse_name, null as database_name, - coalesce(sum(stg_metering_history.credits_used_compute * daily_rates.effective_rate), 0) as spend + coalesce(sum(stg_metering_history.credits_used_compute * daily_rates.effective_rate), 0) as spend, + spend as spend_net_cloud_services from dates left join {{ ref('stg_metering_history') }} on dates.date = convert_timezone('UTC', stg_metering_history.start_time)::date @@ -95,7 +97,8 @@ serverless_task_spend_daily as ( null as storage_type, null as warehouse_name, stg_serverless_task_history.database_name, - coalesce(sum(stg_serverless_task_history.credits_used * daily_rates.effective_rate), 0) as spend + coalesce(sum(stg_serverless_task_history.credits_used * daily_rates.effective_rate), 0) as spend, + spend as spend_net_cloud_services from dates left join {{ ref('stg_serverless_task_history') }} on dates.date = convert_timezone('UTC', stg_serverless_task_history.start_time)::date @@ -113,7 +116,8 @@ adj_for_incl_cloud_services_daily as ( null as storage_type, null as warehouse_name, null as database_name, - coalesce(sum(stg_metering_daily_history.credits_adjustment_cloud_services * daily_rates.effective_rate), 0) as spend + coalesce(sum(stg_metering_daily_history.credits_adjustment_cloud_services * daily_rates.effective_rate), 0) as spend, + 0 as spend_net_cloud_services from dates left join {{ ref('stg_metering_daily_history') }} on dates.date = stg_metering_daily_history.date @@ -124,14 +128,15 @@ adj_for_incl_cloud_services_daily as ( group by 1, 2, 3, 4 ), -cloud_services_spend_daily as ( +_cloud_services_spend_daily as ( select dates.date, 'Cloud Services' as service, null as storage_type, case when stg_metering_history.name = 'CLOUD_SERVICES_ONLY' then 'Cloud Services Only' else stg_metering_history.name end as warehouse_name, null as database_name, - coalesce(sum(stg_metering_history.credits_used_cloud_services * daily_rates.effective_rate), 0) as spend + coalesce(sum(stg_metering_history.credits_used_cloud_services), 0) as credits_used_cloud_services, + any_value(daily_rates.effective_rate) as effective_rate from dates left join {{ ref('stg_metering_history') }} on dates.date = convert_timezone('UTC', stg_metering_history.start_time)::date @@ -143,6 +148,33 @@ cloud_services_spend_daily as ( group by 1, 2, 3, 4 ), + +credits_billed_daily as ( + select + convert_timezone('UTC', stg_metering_history.start_time)::date as date, + sum(credits_used_compute) as daily_credits_used_compute, + sum(credits_used_cloud_services) as daily_credits_used_cloud_services, + greatest(daily_credits_used_cloud_services - daily_credits_used_compute * 0.1, 0) as daily_billable_cloud_services + from {{ ref('stg_metering_history') }} + group by 1 +), + +cloud_services_spend_daily as ( + select + _cloud_services_spend_daily.date, + _cloud_services_spend_daily.service, + _cloud_services_spend_daily.storage_type, + _cloud_services_spend_daily.warehouse_name, + _cloud_services_spend_daily.database_name, + _cloud_services_spend_daily.credits_used_cloud_services*_cloud_services_spend_daily.effective_rate as spend, + + (div0(_cloud_services_spend_daily.credits_used_cloud_services, 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 + from _cloud_services_spend_daily + inner join credits_billed_daily on + _cloud_services_spend_daily.date=credits_billed_daily.date + +) + automatic_clustering_spend_daily as ( select dates.date, @@ -150,7 +182,8 @@ automatic_clustering_spend_daily as ( null as storage_type, null as warehouse_name, null as database_name, - coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend + coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend, + spend as spend_net_cloud_services from dates left join {{ ref('stg_metering_history') }} on dates.date = convert_timezone('UTC', stg_metering_history.start_time)::date @@ -169,7 +202,8 @@ materialized_view_spend_daily as ( null as storage_type, null as warehouse_name, null as database_name, - coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend + coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend, + spend as spend_net_cloud_services from dates left join {{ ref('stg_metering_history') }} on dates.date = convert_timezone('UTC', stg_metering_history.start_time)::date @@ -188,7 +222,8 @@ snowpipe_spend_daily as ( null as storage_type, null as warehouse_name, null as database_name, - coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend + coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend, + spend as spend_net_cloud_services from dates left join {{ ref('stg_metering_history') }} on dates.date = convert_timezone('UTC', stg_metering_history.start_time)::date @@ -207,7 +242,8 @@ query_acceleration_spend_daily as ( null as storage_type, null as warehouse_name, null as database_name, - coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend + coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend, + spend as spend_net_cloud_services from dates left join {{ ref('stg_metering_history') }} on dates.date = convert_timezone('UTC', stg_metering_history.start_time)::date @@ -226,7 +262,8 @@ replication_spend_daily as ( null as storage_type, null as warehouse_name, null as database_name, - coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend + coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend, + spend as spend_net_cloud_services from dates left join {{ ref('stg_metering_history') }} on dates.date = convert_timezone('UTC', stg_metering_history.start_time)::date @@ -245,7 +282,8 @@ search_optimization_spend_daily as ( null as storage_type, null as warehouse_name, null as database_name, - coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend + coalesce(sum(stg_metering_history.credits_used * daily_rates.effective_rate), 0) as spend, + spend as spend_net_cloud_services from dates left join {{ ref('stg_metering_history') }} on dates.date = convert_timezone('UTC', stg_metering_history.start_time)::date From 3ce069c3e7a044188f692e6d5ed9d69b26d042e8 Mon Sep 17 00:00:00 2001 From: Ian Whitestone Date: Fri, 17 Feb 2023 09:50:50 -0500 Subject: [PATCH 2/4] Add spend_net_cloud_services --- .gitignore | 1 + models/daily_spend.sql | 10 +++++----- 2 files changed, 6 insertions(+), 5 deletions(-) diff --git a/.gitignore b/.gitignore index 0606e5c..209b14c 100644 --- a/.gitignore +++ b/.gitignore @@ -3,3 +3,4 @@ dbt_packages/ logs/ logfile .DS_Store +env.sh diff --git a/models/daily_spend.sql b/models/daily_spend.sql index 14b1554..f1d3a35 100644 --- a/models/daily_spend.sql +++ b/models/daily_spend.sql @@ -6,7 +6,7 @@ with date_spine as ( {% set stg_warehouse_metering_history_relation = load_relation(ref('stg_warehouse_metering_history')) %} {% if stg_warehouse_metering_history_relation %} {% set results = run_query("select dateadd(day, 1, timestampadd(hour, -1, convert_timezone('UTC', min(start_time)))::date) from " ~ ref('stg_warehouse_metering_history')) %} {# first complete day #} -- noqa - {% set start_date = "'" ~ results.columns[0][0] ~ "'" %} +{% set start_date = "'" ~ results.columns[0][0] ~ "'" %} {% else %} {% set start_date = "dateadd(day, -1, convert_timezone('UTC', current_timestamp)::date)" %} {# this is just a dummy date for initial compilations before stg_warehouse_metering_history exists #} {% endif %} @@ -151,7 +151,7 @@ _cloud_services_spend_daily as ( credits_billed_daily as ( select - convert_timezone('UTC', stg_metering_history.start_time)::date as date, + convert_timezone('UTC', start_time)::date as date, sum(credits_used_compute) as daily_credits_used_compute, sum(credits_used_cloud_services) as daily_credits_used_cloud_services, greatest(daily_credits_used_cloud_services - daily_credits_used_compute * 0.1, 0) as daily_billable_cloud_services @@ -166,14 +166,14 @@ cloud_services_spend_daily as ( _cloud_services_spend_daily.storage_type, _cloud_services_spend_daily.warehouse_name, _cloud_services_spend_daily.database_name, - _cloud_services_spend_daily.credits_used_cloud_services*_cloud_services_spend_daily.effective_rate as spend, + _cloud_services_spend_daily.credits_used_cloud_services * _cloud_services_spend_daily.effective_rate as spend, (div0(_cloud_services_spend_daily.credits_used_cloud_services, 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 from _cloud_services_spend_daily inner join credits_billed_daily on - _cloud_services_spend_daily.date=credits_billed_daily.date + _cloud_services_spend_daily.date = credits_billed_daily.date -) +), automatic_clustering_spend_daily as ( select From 8e91c58551451fd7e5c19ff893b5a70938942f53 Mon Sep 17 00:00:00 2001 From: Ian Whitestone Date: Fri, 17 Feb 2023 09:59:35 -0500 Subject: [PATCH 3/4] Release 2.0.1 with spend_net_cloud_services --- .changes/2.0.1.md | 7 +++++++ CHANGELOG.md | 8 ++++++++ README.md | 2 +- dbt_project.yml | 2 +- documentation/sample_queries.md | 7 +++---- 5 files changed, 20 insertions(+), 6 deletions(-) create mode 100644 .changes/2.0.1.md diff --git a/.changes/2.0.1.md b/.changes/2.0.1.md new file mode 100644 index 0000000..27a03ae --- /dev/null +++ b/.changes/2.0.1.md @@ -0,0 +1,7 @@ +## dbt-snowflake-monitoring 2.0.1 - February 17, 2023 + +### Fixes + +- Add spend_net_cloud_services ([#80](https://github.com/get-select/dbt-snowflake-monitoring/pull/80)) + + diff --git a/CHANGELOG.md b/CHANGELOG.md index 8e0d8d4..23bc741 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 2.0.1 - February 17, 2023 + +### Fixes + +- Add spend_net_cloud_services ([#80](https://github.com/get-select/dbt-snowflake-monitoring/pull/80)) + + + ## dbt-snowflake-monitoring 2.0.0 - February 08, 2023 The most significant change in 2.0.0 is using query tags instead of comments to attach dbt metadata to queries. To upgrade from previous versions: diff --git a/README.md b/README.md index be1e212..2bad352 100644 --- a/README.md +++ b/README.md @@ -15,7 +15,7 @@ Add the following to your `packages.yml` file: ```yaml packages: - package: get-select/dbt_snowflake_monitoring - version: 2.0.0 + version: 2.0.1 ``` To attribute costs to individual models via the `dbt_metadata` column in the `query_history_enriched` model, query tags are added to all dbt-issued queries. To configure the tags, follow one of the two options below. diff --git a/dbt_project.yml b/dbt_project.yml index 5e2e1ef..604a7b1 100644 --- a/dbt_project.yml +++ b/dbt_project.yml @@ -1,5 +1,5 @@ name: 'dbt_snowflake_monitoring' -version: '2.0.0' +version: '2.0.1' config-version: 2 profile: dbt_snowflake_monitoring diff --git a/documentation/sample_queries.md b/documentation/sample_queries.md index e994009..63278ac 100644 --- a/documentation/sample_queries.md +++ b/documentation/sample_queries.md @@ -29,12 +29,11 @@ This query uses the `daily_spend` model to explore spend by warehouse name. Some ```sql select date_trunc(month, date)::date as month, - service, warehouse_name, - sum(spend) + sum(spend_net_cloud_services) as spend from daily_spend -where service in ('Compute', 'Cloud Services', 'Adj For Incl Cloud Services') -group by 1, 2, 3 +where service in ('Compute', 'Cloud Services') +group by 1, 2 ``` ## Storage Costs From f18f26878ea849eb493a8d624abeda6e7cf481e4 Mon Sep 17 00:00:00 2001 From: Ian Whitestone Date: Sun, 19 Feb 2023 10:53:19 -0500 Subject: [PATCH 4/4] Use metering_daily_history for daily_billable_cloud_services --- models/daily_spend.sql | 10 +++++----- models/staging/stg_metering_daily_history.sql | 2 ++ 2 files changed, 7 insertions(+), 5 deletions(-) diff --git a/models/daily_spend.sql b/models/daily_spend.sql index f1d3a35..33a65db 100644 --- a/models/daily_spend.sql +++ b/models/daily_spend.sql @@ -148,14 +148,14 @@ _cloud_services_spend_daily as ( group by 1, 2, 3, 4 ), - credits_billed_daily as ( select - convert_timezone('UTC', start_time)::date as date, - sum(credits_used_compute) as daily_credits_used_compute, + date, sum(credits_used_cloud_services) as daily_credits_used_cloud_services, - greatest(daily_credits_used_cloud_services - daily_credits_used_compute * 0.1, 0) as daily_billable_cloud_services - from {{ ref('stg_metering_history') }} + sum(credits_used_cloud_services + credits_adjustment_cloud_services) as daily_billable_cloud_services + from {{ ref('stg_metering_daily_history') }} + where + service_type = 'WAREHOUSE_METERING' group by 1 ), diff --git a/models/staging/stg_metering_daily_history.sql b/models/staging/stg_metering_daily_history.sql index 77d7ebb..e512e1c 100644 --- a/models/staging/stg_metering_daily_history.sql +++ b/models/staging/stg_metering_daily_history.sql @@ -2,5 +2,7 @@ select usage_date as date, + service_type, + credits_used_cloud_services, credits_adjustment_cloud_services from {{ source('snowflake_account_usage', 'metering_daily_history') }}