Skip to content

Enable package to use Snowflake Organisation Account views #1

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Open
wants to merge 32 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from 27 commits
Commits
Show all changes
32 commits
Select commit Hold shift + click to select a range
5a9028b
update models
bisset-a Feb 26, 2025
1c2e124
resolving merge conflicts
bisset-a Feb 26, 2025
e1aa209
fix
bisset-a Feb 27, 2025
9f3ae59
fix
bisset-a Mar 18, 2025
9441a6b
fix
bisset-a Mar 18, 2025
b454928
create org level hourly_spend model
bisset-a Mar 18, 2025
c622d6f
remove account_name col from stg_remaining_balance_daily
bisset-a Mar 18, 2025
f575b39
remove account_name col from stg_remaining_balance_daily downstreams
bisset-a Mar 18, 2025
eec7af9
fix
bisset-a Mar 18, 2025
665d6b2
fix for daily_rates
bisset-a Mar 18, 2025
05986b9
removing invalid columns from hourly_spend_org_level
bisset-a Mar 18, 2025
f6596b1
adding account_name to hourly_spend_org_level
bisset-a Mar 18, 2025
da2a75b
adding aliases in hourly_spend_org_level
bisset-a Mar 18, 2025
2d5b055
syntax fix hourly_spend_org_level
bisset-a Mar 18, 2025
940683f
adding account_locator it unique key of incremental models
bisset-a Mar 18, 2025
b48479a
update cost_per_query to support org views
bisset-a Mar 18, 2025
920a041
syntax fix cost_per_query
bisset-a Mar 18, 2025
b89364e
typo
bisset-a Mar 18, 2025
fdd0501
create org level daily_spend model
bisset-a Mar 18, 2025
ee96481
dynamic unique key cost_per_query
bisset-a Mar 19, 2025
f0a7fff
dynamic unique key stg_warehouse_metering_history
bisset-a Mar 19, 2025
bf5679c
fix columns cost_per_query
bisset-a Mar 19, 2025
b53faa9
change daily_rates to use account_locator instead of account_name
bisset-a Mar 19, 2025
cb5585c
remove invalid cols
bisset-a Mar 19, 2025
5576c07
dynamic unique key incrementals
bisset-a Mar 19, 2025
f76aca5
add account_locator to daily_rates partition
bisset-a Mar 19, 2025
2cd82b7
replace org columns and unique key with macros
bisset-a Mar 24, 2025
a2b34c0
removing unique key macro
bisset-a Mar 24, 2025
701fe29
adding comments to conditionally disabled models
bisset-a Mar 25, 2025
29d325e
Merge branch 'main' into annab-support-org-views
bisset-a Mar 25, 2025
62cb54b
adding comments to conditionally disabled models
bisset-a Mar 25, 2025
2add855
remove redundant filter cost_per_query
bisset-a Mar 25, 2025
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
4 changes: 4 additions & 0 deletions dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -13,3 +13,7 @@ clean-targets:
models:
# The config below applies only when running this package directly as a project, not when installed as a package in another project.
+on_schema_change: "append_new_columns"

# vars:
# dbt_snowflake_monitoring:
# uses_org_view: false # default to false
11 changes: 11 additions & 0 deletions macros/add_account_columns.sql

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

👌

Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
{% macro add_account_columns() %}
{% if var('uses_org_view', false) %}
organization_name,
account_name,
account_locator,
{% else %}
current_organization_name() as organization_name,
current_account_name() as account_name,
current_account() as account_locator,
{% endif %}
{% endmacro %}
7 changes: 7 additions & 0 deletions macros/generate_scoped_unique_key.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
{% macro generate_scoped_unique_key(base_fields) %}

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I just realised that if we're now adding the account_name column everywhere, we can always add the account_name to the unique key config! :)

Copy link
Owner Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I just realised this too!! 😆 my only concern was for backwards compatibility for incremental models, account_name would be null for historical data but I think in this case it might be ok to have nulls in the unique_key since the other fields will be unique anyway. other option would be to create a new column called _unique_key that uses generate_surrogate_keys to handle the nulls and use that as the unique_key. wdyt?

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I think a composite PK works totally fine without making a new column - honestly I could go either way.

Copy link
Owner Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

perfect - lets leave it as it! thanks Niall!

{% if var('uses_org_view', false) %}
['account_name', {{ base_fields|join(', ') }}]
{% else %}
{{ base_fields }}
{% endif %}
{% endmacro %}
59 changes: 56 additions & 3 deletions models/cost_per_query.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
{{ config(
materialized='incremental',
unique_key=['query_id', 'start_time'],
unique_key=generate_scoped_unique_key(['query_id', 'start_time'])
) }}

with
Expand All @@ -11,6 +11,7 @@ stop_threshold as (

filtered_queries as (
select
{{ add_account_columns() }}
query_id,
query_text as original_query_text,
credits_used_cloud_services,
Expand Down Expand Up @@ -77,6 +78,22 @@ query_seconds_per_hour as (
from query_hours
),

{% if var('uses_org_view', false) %}
credits_billed_hourly as (
select
start_time as hour,
organization_name,
account_name,
account_locator,
warehouse_id,
sum(credits_used_compute) as credits_used_compute,
sum(credits_used_cloud_services) as credits_used_cloud_services,
from {{ ref('stg_warehouse_metering_history') }}
where true
and service_type = 'WAREHOUSE_METERING'
group by 1, 2, 3, 4, 5
),
{% else %}
credits_billed_hourly as (
select
start_time as hour,
Expand All @@ -89,75 +106,98 @@ credits_billed_hourly as (
and service_type in ('QUERY_ACCELERATION', 'WAREHOUSE_METERING')
group by 1, 2
),
{% endif %}

query_cost as (
select
query_seconds_per_hour.*,
credits_billed_hourly.credits_used_compute * query_seconds_per_hour.fraction_of_total_query_time_in_hour as allocated_compute_credits_in_hour,
allocated_compute_credits_in_hour * daily_rates.effective_rate as allocated_compute_cost_in_hour,
{% if not var('uses_org_view', false) %}
credits_billed_hourly.credits_used_query_acceleration * query_seconds_per_hour.fraction_of_total_query_acceleration_bytes_scanned_in_hour as allocated_query_acceleration_credits_in_hour,
allocated_query_acceleration_credits_in_hour * daily_rates.effective_rate as allocated_query_acceleration_cost_in_hour
{% endif %}
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
and query_seconds_per_hour.account_name = credits_billed_hourly.account_name
inner join {{ ref('daily_rates') }} as daily_rates
on date(query_seconds_per_hour.start_time) = daily_rates.date
and daily_rates.service_type = 'WAREHOUSE_METERING'
and daily_rates.usage_type = 'compute'
and daily_rates.account_name = query_seconds_per_hour.account_name
),

cost_per_query as (
select
organization_name,
account_name,
account_locator,
query_id,
any_value(start_time) as start_time,
any_value(end_time) as end_time,
any_value(execution_start_time) as execution_start_time,
sum(allocated_compute_cost_in_hour) as compute_cost,
sum(allocated_compute_credits_in_hour) as compute_credits,
{% if not var('uses_org_view', false) %}
sum(allocated_query_acceleration_cost_in_hour) as query_acceleration_cost,
sum(allocated_query_acceleration_credits_in_hour) as query_acceleration_credits,
{% endif %}
any_value(credits_used_cloud_services) as credits_used_cloud_services,
any_value(ran_on_warehouse) as ran_on_warehouse
from query_cost
group by 1
group by all
),

credits_billed_daily as (
select
date(hour) as date,
organization_name,
account_name,
account_locator,
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 credits_billed_hourly
group by 1
group by all
),

all_queries as (
select
organization_name,
account_name,
account_locator,
query_id,
start_time,
end_time,
execution_start_time,
compute_cost,
compute_credits,
{% if not var('uses_org_view', false) %}
query_acceleration_cost,
query_acceleration_credits,
{% endif %}
credits_used_cloud_services,
ran_on_warehouse
from cost_per_query

union all

select
organization_name,
account_name,
account_locator,
query_id,
start_time,
end_time,
execution_start_time,
0 as compute_cost,
0 as compute_credits,
{% if not var('uses_org_view', false) %}
0 as query_acceleration_cost,
0 as query_acceleration_credits,
{% endif %}
credits_used_cloud_services,
ran_on_warehouse
from filtered_queries
Expand All @@ -166,33 +206,46 @@ all_queries as (
)

select
all_queries.organization_name,
all_queries.account_name,
all_queries.account_locator,
all_queries.query_id,
all_queries.start_time,
all_queries.end_time,
all_queries.execution_start_time,
all_queries.compute_cost,
all_queries.compute_credits,
{% if not var('uses_org_view', false) %}
all_queries.query_acceleration_cost,
all_queries.query_acceleration_credits,
{% endif %}
-- For the most recent day, which is not yet complete, this calculation won't be perfect.
-- For example, at 12PM on the latest day, it's possible that cloud credits make up <10% of compute cost, so the queries
-- from that day are not allocated any cloud_services_cost. The next time the model runs, after we have the full day of data,
-- this may change if cloud credits make up >10% of compute cost.
(div0(all_queries.credits_used_cloud_services, credits_billed_daily.daily_credits_used_cloud_services) * credits_billed_daily.daily_billable_cloud_services) * coalesce(daily_rates.effective_rate, current_rates.effective_rate) as cloud_services_cost,
div0(all_queries.credits_used_cloud_services, credits_billed_daily.daily_credits_used_cloud_services) * credits_billed_daily.daily_billable_cloud_services as cloud_services_credits,
{% if var('uses_org_view', false) %}
all_queries.compute_cost + cloud_services_cost as query_cost,
all_queries.compute_credits + cloud_services_credits as query_credits,
{% else %}
all_queries.compute_cost + all_queries.query_acceleration_cost + cloud_services_cost as query_cost,
all_queries.compute_credits + all_queries.query_acceleration_credits + cloud_services_credits as query_credits,
{% endif %}
all_queries.ran_on_warehouse,
coalesce(daily_rates.currency, current_rates.currency) as currency
from all_queries
inner join credits_billed_daily
on date(all_queries.start_time) = credits_billed_daily.date
and all_queries.account_name = credits_billed_daily.account_name
left join {{ ref('daily_rates') }} as daily_rates
on date(all_queries.start_time) = daily_rates.date
and daily_rates.service_type = 'CLOUD_SERVICES'
and daily_rates.usage_type = 'cloud services'
and daily_rates.account_name = all_queries.account_name
inner join {{ ref('daily_rates') }} as current_rates
on current_rates.is_latest_rate
and current_rates.service_type = 'CLOUD_SERVICES'
and current_rates.usage_type = 'cloud services'
and current_rates.account_name = all_queries.account_name
order by all_queries.start_time asc
71 changes: 53 additions & 18 deletions models/daily_rates.sql
Original file line number Diff line number Diff line change
Expand Up @@ -23,14 +23,19 @@ dates_base as (

rate_sheet_daily_base as (
select
organization_name,
account_name,
account_locator,
date,
usage_type,
currency,
effective_rate,
service_type
from {{ ref('stg_rate_sheet_daily') }}
{% if not var('uses_org_view', false) %}
where
account_locator = {{ account_locator() }}
{% endif %}
),

stop_thresholds as (
Expand Down Expand Up @@ -79,15 +84,17 @@ rates_date_range_w_usage_types as (
select
date_range.start_date,
date_range.end_date,
usage_types.account_name,
usage_types.usage_type
from date_range
cross join (select distinct rate_sheet_daily.usage_type from rate_sheet_daily) as usage_types
cross join (select distinct rate_sheet_daily.account_name, rate_sheet_daily.usage_type from rate_sheet_daily) as usage_types
),

base as (
select
db.date,
dr.usage_type
dr.usage_type,
dr.account_name
from dates_base as db
inner join rates_date_range_w_usage_types as dr
on db.date between dr.start_date and dr.end_date
Expand All @@ -97,26 +104,45 @@ rates_w_overage as (
select
base.date,
base.usage_type,
base.account_name,
coalesce(
rate_sheet_daily.service_type,
lag(rate_sheet_daily.service_type) ignore nulls over (partition by base.usage_type
order by base.date),
lead(rate_sheet_daily.service_type) ignore nulls over (partition by base.usage_type
order by base.date)
lag(rate_sheet_daily.service_type) ignore nulls over (
partition by base.usage_type
, base.account_name
order by base.date
),
lead(rate_sheet_daily.service_type) ignore nulls over (
partition by base.usage_type
, base.account_name
order by base.date
)
) as service_type,
coalesce(
rate_sheet_daily.effective_rate,
lag(rate_sheet_daily.effective_rate) ignore nulls over (partition by base.usage_type
order by base.date),
lead(rate_sheet_daily.effective_rate) ignore nulls over (partition by base.usage_type
order by base.date)
lag(rate_sheet_daily.effective_rate) ignore nulls over (
partition by base.usage_type
, base.account_name
order by base.date
),
lead(rate_sheet_daily.effective_rate) ignore nulls over (
partition by base.usage_type
, base.account_name
order by base.date
)
) as effective_rate,
coalesce(
rate_sheet_daily.currency,
lag(rate_sheet_daily.currency) ignore nulls over (partition by base.usage_type
order by base.date),
lead(rate_sheet_daily.currency) ignore nulls over (partition by base.usage_type
order by base.date)
lag(rate_sheet_daily.currency) ignore nulls over (
partition by base.usage_type
, base.account_name
order by base.date
),
lead(rate_sheet_daily.currency) ignore nulls over (
partition by base.usage_type
, base.account_name
order by base.date
)
) as currency,
base.usage_type like 'overage-%' as is_overage_rate,
replace(base.usage_type, 'overage-', '') as associated_usage_type,
Expand All @@ -134,30 +160,39 @@ order by base.date)
left join rate_sheet_daily
on base.date = rate_sheet_daily.date
and base.usage_type = rate_sheet_daily.usage_type
and base.account_name = rate_sheet_daily.account_name
),

rates as (
select
date,
account_name,
usage_type,
associated_usage_type,
service_type,
effective_rate,
currency,
is_overage_rate
from rates_w_overage
qualify row_number() over (partition by date, service_type, associated_usage_type
order by rate_priority desc) = 1
qualify row_number() over (
partition by date, service_type, associated_usage_type
, account_name
order by rate_priority desc
) = 1
)

select
date,
account_name,
associated_usage_type as usage_type,
service_type,
effective_rate,
currency,
is_overage_rate,
row_number() over (partition by service_type, associated_usage_type
order by date desc) = 1 as is_latest_rate
row_number() over (
partition by service_type, associated_usage_type
, account_name
order by date desc
) = 1 as is_latest_rate
from rates
order by date
4 changes: 4 additions & 0 deletions models/daily_spend.sql
Original file line number Diff line number Diff line change
@@ -1,3 +1,7 @@
{{
config(
enabled=not(var('uses_org_view', false)))
}}
select
convert_timezone('UTC', hour)::date as date, -- get UTC date to align with Snowflake billing
service,
Expand Down
4 changes: 2 additions & 2 deletions models/dbt_queries.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
{{ config(
materialized='incremental',
unique_key=['query_id', 'start_time']
unique_key=generate_scoped_unique_key(['query_id', 'start_time'])
) }}

select
Expand Down Expand Up @@ -51,7 +51,7 @@ select
from {{ ref('query_history_enriched') }}
where dbt_metadata is not null
{% if is_incremental() %}
-- Conservatively re-process the last 3 days to account for late arriving rates data which changes the cost per query.
-- Conservatively re-process the last 3 days to account for late arriving rates data which changes the cost per query.
-- Allow an override from project variable
and end_time > (select coalesce(dateadd(day, -{{ var('dbt_snowflake_monitoring_incremental_days', '3') }}, max(end_time)), '1970-01-01') from {{ this }})
{% endif %}
Loading