Skip to content

Commit b51598a

Browse files
authored
Divide unattributed storage cost by # of clusters utilizing disk (#5447)
1 parent db9fce8 commit b51598a

File tree

2 files changed

+20
-16
lines changed

2 files changed

+20
-16
lines changed

koku/masu/database/trino_sql/reporting_ocpawscostlineitem_daily_summary.sql

+13-11
Original file line numberDiff line numberDiff line change
@@ -743,12 +743,14 @@ INSERT INTO hive.{{schema | sqlsafe}}.reporting_ocpawscostlineitem_project_daily
743743
WITH cte_total_pv_capacity as (
744744
SELECT
745745
aws_resource_id,
746-
SUM(combined_requests.capacity) as total_pv_capacity
746+
SUM(combined_requests.capacity) as total_pv_capacity,
747+
count(distinct cluster_id) as cluster_count
747748
FROM (
748749
SELECT
749750
ocp.persistentvolume,
750751
max(ocp.persistentvolumeclaim_capacity_gigabyte) as capacity,
751-
aws.resource_id as aws_resource_id
752+
aws.resource_id as aws_resource_id,
753+
ocp.cluster_id
752754
FROM hive.{{schema | sqlsafe}}.reporting_ocpusagelineitem_daily_summary as ocp
753755
JOIN hive.{{schema | sqlsafe}}.aws_openshift_daily_resource_matched_temp as aws
754756
ON (aws.usage_start = ocp.usage_start)
@@ -762,7 +764,7 @@ WITH cte_total_pv_capacity as (
762764
AND aws.ocp_source = {{ocp_source_uuid}}
763765
AND aws.year = {{year}}
764766
AND aws.month = {{month}}
765-
GROUP BY ocp.persistentvolume, aws.resource_id
767+
GROUP BY ocp.persistentvolume, aws.resource_id, ocp.cluster_id
766768
) as combined_requests group by aws_resource_id
767769
)
768770
SELECT cast(uuid() as varchar) as aws_uuid, -- need a new uuid or it will deduplicate
@@ -785,14 +787,14 @@ SELECT cast(uuid() as varchar) as aws_uuid, -- need a new uuid or it will dedup
785787
max(aws.unit) as unit,
786788
cast(NULL as double) as usage_amount,
787789
max(aws.currency_code) as currency_code,
788-
(max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.unblended_cost) as unblended_cost,
789-
((max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.unblended_cost)) * cast({{markup}} as decimal(24,9)) as markup_cost,
790-
(max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.blended_cost) as blended_cost,
791-
((max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.blended_cost)) * cast({{markup}} as decimal(24,9)) as markup_cost_blended,
792-
(max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.savingsplan_effective_cost) as savingsplan_effective_cost,
793-
((max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.savingsplan_effective_cost)) * cast({{markup}} as decimal(24,9)) as markup_cost_savingsplan,
794-
(max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.calculated_amortized_cost) as calculated_amortized_cost,
795-
((max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.calculated_amortized_cost)) * cast({{markup}} as decimal(24,9)) as markup_cost_amortized,
790+
(max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.unblended_cost) / max(pv_cap.cluster_count) as unblended_cost,
791+
((max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.unblended_cost)) * cast({{markup}} as decimal(24,9)) / max(pv_cap.cluster_count) as markup_cost,
792+
(max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.blended_cost) / max(pv_cap.cluster_count) as blended_cost,
793+
((max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.blended_cost)) * cast({{markup}} as decimal(24,9)) / max(pv_cap.cluster_count) as markup_cost_blended,
794+
(max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.savingsplan_effective_cost) / max(pv_cap.cluster_count) as savingsplan_effective_cost,
795+
((max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.savingsplan_effective_cost)) * cast({{markup}} as decimal(24,9)) / max(pv_cap.cluster_count) as markup_cost_savingsplan,
796+
(max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.calculated_amortized_cost) / max(pv_cap.cluster_count) as calculated_amortized_cost,
797+
((max(aws_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(aws_disk.capacity) * max(aws.calculated_amortized_cost)) * cast({{markup}} as decimal(24,9)) / max(pv_cap.cluster_count) as markup_cost_amortized,
796798
max(aws.resource_id_matched) as resource_id_matched,
797799
{{ocp_source_uuid}} as ocp_source,
798800
max(aws.year) as year,

koku/masu/database/trino_sql/reporting_ocpazurecostlineitem_daily_summary.sql

+7-5
Original file line numberDiff line numberDiff line change
@@ -496,12 +496,14 @@ INSERT INTO hive.{{schema | sqlsafe}}.reporting_ocpazurecostlineitem_project_dai
496496
WITH cte_total_pv_capacity as (
497497
SELECT
498498
azure_resource_id,
499-
SUM(combined_requests.capacity) as total_pv_capacity
499+
SUM(combined_requests.capacity) as total_pv_capacity,
500+
count(distinct cluster_id) as cluster_count
500501
FROM (
501502
SELECT
502503
ocp.persistentvolume,
503504
max(ocp.persistentvolumeclaim_capacity_gigabyte) as capacity,
504-
azure.resource_id as azure_resource_id
505+
azure.resource_id as azure_resource_id,
506+
ocp.cluster_id
505507
FROM hive.{{schema | sqlsafe}}.reporting_ocpusagelineitem_daily_summary as ocp
506508
JOIN hive.{{schema | sqlsafe}}.azure_openshift_daily_resource_matched_temp as azure
507509
ON (azure.usage_start = ocp.usage_start)
@@ -517,7 +519,7 @@ WITH cte_total_pv_capacity as (
517519
AND azure.ocp_source = {{ocp_source_uuid}}
518520
AND azure.year = {{year}}
519521
AND azure.month = {{month}}
520-
GROUP BY ocp.persistentvolume, azure.resource_id
522+
GROUP BY ocp.persistentvolume, azure.resource_id, ocp.cluster_id
521523
) as combined_requests group by azure_resource_id
522524
)
523525
SELECT cast(uuid() as varchar) as azure_uuid, -- need a new uuid or it will deduplicate
@@ -538,8 +540,8 @@ SELECT cast(uuid() as varchar) as azure_uuid, -- need a new uuid or it will dedu
538540
max(nullif(azure.resource_location, '')) as resource_location,
539541
'GB-Mo' as unit_of_measure, -- Has to have this unit to show up on storage endpoint
540542
max(azure.currency) as currency,
541-
(max(az_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(az_disk.capacity) * max(azure.pretax_cost) as pretax_cost,
542-
((max(az_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(az_disk.capacity) * max(azure.pretax_cost)) * cast({{markup}} as decimal(24,9)) as markup_cost, -- pretax_cost x markup = markup_cost
543+
(max(az_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(az_disk.capacity) * max(azure.pretax_cost) / max(pv_cap.cluster_count) as pretax_cost,
544+
((max(az_disk.capacity) - max(pv_cap.total_pv_capacity)) / max(az_disk.capacity) * max(azure.pretax_cost)) * cast({{markup}} as decimal(24,9)) / max(pv_cap.cluster_count) as markup_cost, -- pretax_cost x markup = markup_cost
543545
max(azure.resource_id_matched) as resource_id_matched,
544546
{{ocp_source_uuid}} as ocp_source,
545547
max(azure.year) as year,

0 commit comments

Comments
 (0)