Skip to content

Commit

Permalink
Merge pull request #80 from get-select/net_cloud_services
Browse files Browse the repository at this point in the history
Add spend_net_cloud_services
  • Loading branch information
ian-whitestone authored Feb 20, 2023
2 parents aef2e53 + f18f268 commit 2a6179e
Show file tree
Hide file tree
Showing 8 changed files with 74 additions and 19 deletions.
7 changes: 7 additions & 0 deletions .changes/2.0.1.md
Original file line number Diff line number Diff line change
@@ -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))


1 change: 1 addition & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -3,3 +3,4 @@ dbt_packages/
logs/
logfile
.DS_Store
env.sh
8 changes: 8 additions & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -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:

Expand Down
2 changes: 1 addition & 1 deletion README.md
Original file line number Diff line number Diff line change
Expand Up @@ -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.
Expand Down
2 changes: 1 addition & 1 deletion dbt_project.yml
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
name: 'dbt_snowflake_monitoring'
version: '2.0.0'
version: '2.0.1'
config-version: 2

profile: dbt_snowflake_monitoring
Expand Down
7 changes: 3 additions & 4 deletions documentation/sample_queries.md
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
64 changes: 51 additions & 13 deletions models/daily_spend.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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 %}
Expand Down Expand Up @@ -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') }}
Expand All @@ -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
Expand All @@ -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
Expand All @@ -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
Expand All @@ -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
Expand All @@ -143,14 +148,42 @@ cloud_services_spend_daily as (
group by 1, 2, 3, 4
),

credits_billed_daily as (
select
date,
sum(credits_used_cloud_services) as daily_credits_used_cloud_services,
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
),

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,
'Automatic Clustering' as service,
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
Expand All @@ -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
Expand All @@ -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
Expand All @@ -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
Expand All @@ -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
Expand All @@ -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
Expand Down
2 changes: 2 additions & 0 deletions models/staging/stg_metering_daily_history.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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') }}

0 comments on commit 2a6179e

Please sign in to comment.