Skip to content
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

KPI savings estimations additions #624

Open
wants to merge 2 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
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
37 changes: 36 additions & 1 deletion cid/builtin/core/data/queries/kpi/kpi_ebs_storage_view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -75,6 +75,18 @@ ebs_spend_with_unit_cost AS (
WHEN usage_storage_gb_mo <= 150 THEN 0
ELSE 125
END AS gp2_usage_added_throughput_gibps_mo
-->>SAVINGS: look at inverse from a current gp3 perspective
, CASE WHEN volume_api_name <> 'gp3' THEN 0
WHEN usage_storage_gb_mo*3 < 3000 THEN 3000 - 3000
WHEN usage_storage_gb_mo*3 > 16000 THEN 16000 - 3000
ELSE usage_storage_gb_mo*3 - 3000
END equiv_gp2_usage_added_iops_mo
, CASE
WHEN volume_api_name <> 'gp3' THEN 0
WHEN usage_storage_gb_mo <= 150 THEN 0
ELSE 125
END equiv_gp2_usage_added_throughput_gibps_mo
--<<SAVINGS
, cost_storage_gb_mo + cost_iops_mo + cost_throughput_gibps_mo AS ebs_all_cost
, CASE
WHEN volume_api_name = 'sc1' THEN (cost_iops_mo + cost_throughput_gibps_mo + cost_storage_gb_mo)
Expand Down Expand Up @@ -108,6 +120,12 @@ ebs_spend_with_unit_cost AS (
WHEN volume_api_name = 'gp2' THEN cost_storage_gb_mo*0.8/usage_storage_gb_mo
ELSE 0
END AS "estimated_gp3_unit_cost"
-->>SAVINGS: look at inverse from a current gp3 perspective
, CASE
WHEN volume_api_name = 'gp3' THEN (cost_storage_gb_mo/0.8) / usage_storage_gb_mo
ELSE 0
END "estimated_gp2_unit_cost"
--<<SAVINGS
FROM
ebs_spend
),
Expand All @@ -124,6 +142,10 @@ ebs_before_map AS (
, sum(usage_throughput_gibps_mo) AS usage_throughput_gibps_mo
, sum(gp2_usage_added_iops_mo) gp2_usage_added_iops_mo
, sum(gp2_usage_added_throughput_gibps_mo) AS gp2_usage_added_throughput_gibps_mo
-->>SAVINGS: look at inverse from a current gp3 perspective
, sum(equiv_gp2_usage_added_iops_mo) equiv_gp2_usage_added_iops_mo
, sum(equiv_gp2_usage_added_throughput_gibps_mo) equiv_gp2_usage_added_throughput_gibps_mo
--<<SAVINGS
, sum(ebs_all_cost) AS ebs_all_cost
, sum(ebs_sc1_cost) AS ebs_sc1_cost
, sum(ebs_st1_cost) AS ebs_st1_cost
Expand All @@ -137,14 +159,24 @@ ebs_before_map AS (
- Storage always 20% cheaper
- Additional iops per iops-mo is 6% of the cost of 1 gp3 GB-mo
- Additional throughput per gibps-mo is 50% of the cost of 1 gp3 GB-mo */
, sum(CASE
, sum(CASE
/*ignore non gp2' */
WHEN volume_api_name = 'gp2' THEN ebs_gp2_cost
- (cost_storage_gb_mo*0.8
+ estimated_gp3_unit_cost * 0.5 * gp2_usage_added_throughput_gibps_mo
+ estimated_gp3_unit_cost * 0.06 * gp2_usage_added_iops_mo)
ELSE 0
END) AS ebs_gp3_potential_savings
-->>SAVINGS: look at inverse from a current gp3 perspective
, sum(CASE
WHEN (volume_api_name = 'gp3') THEN
(
(cost_storage_gb_mo/0.8) +
(estimated_gp2_unit_cost * 0.5 * equiv_gp2_usage_added_throughput_gibps_mo) +
(estimated_gp2_unit_cost * 0.06 * equiv_gp2_usage_added_iops_mo)
) ELSE 0
END) ebs_gp2_potential_cost
--<<SAVINGS
FROM
ebs_spend_with_unit_cost
GROUP BY 1, 2, 3, 4, 5, 6)
Expand All @@ -170,6 +202,9 @@ SELECT DISTINCT
, ebs_gp2_cost
, ebs_gp3_cost
, ebs_gp3_potential_savings
-->>SAVINGS: look at inverse from a current gp3 perspective
, ebs_gp2_potential_cost - ebs_gp3_cost gp3_current_savings
--<<SAVINGS
FROM
ebs_before_map
LEFT JOIN map ON map.account_id = linked_account_id
53 changes: 52 additions & 1 deletion cid/builtin/core/data/queries/kpi/kpi_instance_all_view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -266,7 +266,58 @@
WHEN (("charge_type" LIKE '%Usage%') AND ("product_code" = 'AWSLambda') AND (adjusted_processor = 'Graviton')) THEN amortized_cost ELSE 0 END "lambda_graviton_cost"
, CASE
WHEN (("charge_type" LIKE '%Usage%') AND ("product_code" = 'AWSLambda') AND (adjusted_processor <> 'Graviton')) THEN amortized_cost*.2 ELSE 0 END "lambda_graviton_potential_savings" /*Uses 20% savings estimate*/


/*Savings estimation*/
-->>SAVINGS:
-- EC2 Graviton current savings
, CASE
WHEN (adjusted_processor = 'Graviton') AND ("charge_type" LIKE '%Usage%') AND ("product_code" = 'AmazonEC2') THEN (amortized_cost / 8E-1) * 2E-1
ELSE 0 END "ec2_graviton_current_savings"
-- EC2 AMD current savings
, CASE
WHEN (adjusted_processor = 'AMD') AND ("charge_type" LIKE '%Usage%') AND ("product_code" = 'AmazonEC2') THEN (amortized_cost / 9E-1) * 1E-1
ELSE 0 END "ec2_amd_current_savings"
-- Spot current savings
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonEC2') AND
("instance_type" <> '') AND
("operation" LIKE '%RunInstances%') AND
(purchase_option = 'Spot') AND (NOT (savings_plan_offering_type LIKE '%EC2%')) THEN (adjusted_amortized_cost / 5.5E-1) * 4.5E-1
ELSE 0 END "ec2_spot_current_savings"
-- Latest generation current savings
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonEC2') AND
("instance_type" <> '') AND
("operation" LIKE '%RunInstances%') AND
(generation IN ('Current')) AND
(purchase_option <> 'Spot') AND
(purchase_option <> 'Reserved') AND
(NOT (savings_plan_offering_type LIKE '%EC2%')) THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "ec2_latest_generation_current_savings"
-- RDS Graviton current savings
, CASE WHEN (adjusted_processor = 'Graviton') AND
("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonRDS') AND
(purchase_option = 'OnDemand') AND
(database_engine IN ('Aurora MySQL', 'Aurora PostgreSQL', 'MariaDB', 'PostgreSQL')) THEN (amortized_cost / 9E-1) * 1E-1
ELSE 0 END "rds_graviton_current_savings"
-- ElastiCache Graviton current savings
, CASE WHEN (adjusted_processor = 'Graviton') AND
("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonElastiCache') THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "elasticache_graviton_current_savings"
-- AOS Graviton current saving
, CASE WHEN ("charge_type" = 'Usage') AND
("product_code" = 'AmazonES') AND
(adjusted_processor = 'Graviton') THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "opensearch_graviton_current_savings"
-- Lambda Graviton current saving
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AWSLambda') AND
(adjusted_processor = 'Graviton') THEN (amortized_cost / 8E-1) 2E-1
ELSE 0 END "lambda_graviton_current_savings"
--<<SAVINGS

FROM
cur_all cur_all
LEFT JOIN instance_map ON (instance_map.product = product_code AND instance_map.family = instance_type_family)
Expand Down
52 changes: 51 additions & 1 deletion cid/builtin/core/data/queries/kpi/kpi_instance_all_view_noRI.sql
Original file line number Diff line number Diff line change
Expand Up @@ -261,7 +261,57 @@
WHEN (("charge_type" LIKE '%Usage%') AND ("product_code" = 'AWSLambda') AND (adjusted_processor = 'Graviton')) THEN amortized_cost ELSE 0 END "lambda_graviton_cost"
, CASE
WHEN (("charge_type" LIKE '%Usage%') AND ("product_code" = 'AWSLambda') AND (adjusted_processor <> 'Graviton')) THEN amortized_cost*.2 ELSE 0 END "lambda_graviton_potential_savings" /*Uses 20% savings estimate*/

/*Savings estimation*/
-->>SAVINGS:
-- EC2 Graviton current savings
, CASE
WHEN (adjusted_processor = 'Graviton') AND ("charge_type" LIKE '%Usage%') AND ("product_code" = 'AmazonEC2') THEN (amortized_cost / 8E-1) * 2E-1
ELSE 0 END "ec2_graviton_current_savings"
-- EC2 AMD current savings
, CASE
WHEN (adjusted_processor = 'AMD') AND ("charge_type" LIKE '%Usage%') AND ("product_code" = 'AmazonEC2') THEN (amortized_cost / 9E-1) * 1E-1
ELSE 0 END "ec2_amd_current_savings"
-- Spot current savings
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonEC2') AND
("instance_type" <> '') AND
("operation" LIKE '%RunInstances%') AND
(purchase_option = 'Spot') AND (NOT (savings_plan_offering_type LIKE '%EC2%')) THEN (adjusted_amortized_cost / 5.5E-1) * 4.5E-1
ELSE 0 END "ec2_spot_current_savings"
-- Latest generation current savings
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonEC2') AND
("instance_type" <> '') AND
("operation" LIKE '%RunInstances%') AND
(generation IN ('Current')) AND
(purchase_option <> 'Spot') AND
(purchase_option <> 'Reserved') AND
(NOT (savings_plan_offering_type LIKE '%EC2%')) THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "ec2_latest_generation_current_savings"
-- RDS Graviton current savings
, CASE WHEN (adjusted_processor = 'Graviton') AND
("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonRDS') AND
(purchase_option = 'OnDemand') AND
(database_engine IN ('Aurora MySQL', 'Aurora PostgreSQL', 'MariaDB', 'PostgreSQL')) THEN (amortized_cost / 9E-1) * 1E-1
ELSE 0 END "rds_graviton_current_savings"
-- ElastiCache Graviton current savings
, CASE WHEN (adjusted_processor = 'Graviton') AND
("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonElastiCache') THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "elasticache_graviton_current_savings"
-- AOS Graviton current saving
, CASE WHEN ("charge_type" = 'Usage') AND
("product_code" = 'AmazonES') AND
(adjusted_processor = 'Graviton') THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "opensearch_graviton_current_savings"
-- Lambda Graviton current saving
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AWSLambda') AND
(adjusted_processor = 'Graviton') THEN (amortized_cost / 8E-1) 2E-1
ELSE 0 END "lambda_graviton_current_savings"
--<<SAVINGS

FROM
cur_all cur_all
LEFT JOIN instance_map ON (instance_map.product = product_code AND instance_map.family = instance_type_family)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -254,7 +254,57 @@
WHEN (("charge_type" LIKE '%Usage%') AND ("product_code" = 'AWSLambda') AND (adjusted_processor = 'Graviton')) THEN amortized_cost ELSE 0 END "lambda_graviton_cost"
, CASE
WHEN (("charge_type" LIKE '%Usage%') AND ("product_code" = 'AWSLambda') AND (adjusted_processor <> 'Graviton')) THEN amortized_cost*.2 ELSE 0 END "lambda_graviton_potential_savings" /*Uses 20% savings estimate*/

/*Savings estimation*/
-->>SAVINGS:
-- EC2 Graviton current savings
, CASE
WHEN (adjusted_processor = 'Graviton') AND ("charge_type" LIKE '%Usage%') AND ("product_code" = 'AmazonEC2') THEN (amortized_cost / 8E-1) * 2E-1
ELSE 0 END "ec2_graviton_current_savings"
-- EC2 AMD current savings
, CASE
WHEN (adjusted_processor = 'AMD') AND ("charge_type" LIKE '%Usage%') AND ("product_code" = 'AmazonEC2') THEN (amortized_cost / 9E-1) * 1E-1
ELSE 0 END "ec2_amd_current_savings"
-- Spot current savings
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonEC2') AND
("instance_type" <> '') AND
("operation" LIKE '%RunInstances%') AND
(purchase_option = 'Spot') AND (NOT (savings_plan_offering_type LIKE '%EC2%')) THEN (adjusted_amortized_cost / 5.5E-1) * 4.5E-1
ELSE 0 END "ec2_spot_current_savings"
-- Latest generation current savings
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonEC2') AND
("instance_type" <> '') AND
("operation" LIKE '%RunInstances%') AND
(generation IN ('Current')) AND
(purchase_option <> 'Spot') AND
(purchase_option <> 'Reserved') AND
(NOT (savings_plan_offering_type LIKE '%EC2%')) THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "ec2_latest_generation_current_savings"
-- RDS Graviton current savings
, CASE WHEN (adjusted_processor = 'Graviton') AND
("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonRDS') AND
(purchase_option = 'OnDemand') AND
(database_engine IN ('Aurora MySQL', 'Aurora PostgreSQL', 'MariaDB', 'PostgreSQL')) THEN (amortized_cost / 9E-1) * 1E-1
ELSE 0 END "rds_graviton_current_savings"
-- ElastiCache Graviton current savings
, CASE WHEN (adjusted_processor = 'Graviton') AND
("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonElastiCache') THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "elasticache_graviton_current_savings"
-- AOS Graviton current saving
, CASE WHEN ("charge_type" = 'Usage') AND
("product_code" = 'AmazonES') AND
(adjusted_processor = 'Graviton') THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "opensearch_graviton_current_savings"
-- Lambda Graviton current saving
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AWSLambda') AND
(adjusted_processor = 'Graviton') THEN (amortized_cost / 8E-1) 2E-1
ELSE 0 END "lambda_graviton_current_savings"
--<<SAVINGS

FROM
cur_all cur_all
LEFT JOIN instance_map ON (instance_map.product = product_code AND instance_map.family = instance_type_family)
Expand Down
52 changes: 51 additions & 1 deletion cid/builtin/core/data/queries/kpi/kpi_instance_all_view_noSP.sql
Original file line number Diff line number Diff line change
Expand Up @@ -257,7 +257,57 @@
WHEN (("charge_type" LIKE '%Usage%') AND ("product_code" = 'AWSLambda') AND (adjusted_processor = 'Graviton')) THEN amortized_cost ELSE 0 END "lambda_graviton_cost"
, CASE
WHEN (("charge_type" LIKE '%Usage%') AND ("product_code" = 'AWSLambda') AND (adjusted_processor <> 'Graviton')) THEN amortized_cost*.2 ELSE 0 END "lambda_graviton_potential_savings" /*Uses 20% savings estimate*/

/*Savings estimation*/
-->>SAVINGS:
-- EC2 Graviton current savings
, CASE
WHEN (adjusted_processor = 'Graviton') AND ("charge_type" LIKE '%Usage%') AND ("product_code" = 'AmazonEC2') THEN (amortized_cost / 8E-1) * 2E-1
ELSE 0 END "ec2_graviton_current_savings"
-- EC2 AMD current savings
, CASE
WHEN (adjusted_processor = 'AMD') AND ("charge_type" LIKE '%Usage%') AND ("product_code" = 'AmazonEC2') THEN (amortized_cost / 9E-1) * 1E-1
ELSE 0 END "ec2_amd_current_savings"
-- Spot current savings
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonEC2') AND
("instance_type" <> '') AND
("operation" LIKE '%RunInstances%') AND
(purchase_option = 'Spot') AND (NOT (savings_plan_offering_type LIKE '%EC2%')) THEN (adjusted_amortized_cost / 5.5E-1) * 4.5E-1
ELSE 0 END "ec2_spot_current_savings"
-- Latest generation current savings
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonEC2') AND
("instance_type" <> '') AND
("operation" LIKE '%RunInstances%') AND
(generation IN ('Current')) AND
(purchase_option <> 'Spot') AND
(purchase_option <> 'Reserved') AND
(NOT (savings_plan_offering_type LIKE '%EC2%')) THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "ec2_latest_generation_current_savings"
-- RDS Graviton current savings
, CASE WHEN (adjusted_processor = 'Graviton') AND
("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonRDS') AND
(purchase_option = 'OnDemand') AND
(database_engine IN ('Aurora MySQL', 'Aurora PostgreSQL', 'MariaDB', 'PostgreSQL')) THEN (amortized_cost / 9E-1) * 1E-1
ELSE 0 END "rds_graviton_current_savings"
-- ElastiCache Graviton current savings
, CASE WHEN (adjusted_processor = 'Graviton') AND
("charge_type" LIKE '%Usage%') AND
("product_code" = 'AmazonElastiCache') THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "elasticache_graviton_current_savings"
-- AOS Graviton current saving
, CASE WHEN ("charge_type" = 'Usage') AND
("product_code" = 'AmazonES') AND
(adjusted_processor = 'Graviton') THEN (amortized_cost / 9.5E-1) * 5E-2
ELSE 0 END "opensearch_graviton_current_savings"
-- Lambda Graviton current saving
, CASE WHEN ("charge_type" LIKE '%Usage%') AND
("product_code" = 'AWSLambda') AND
(adjusted_processor = 'Graviton') THEN (amortized_cost / 8E-1) 2E-1
ELSE 0 END "lambda_graviton_current_savings"
--<<SAVINGS

FROM
cur_all cur_all
LEFT JOIN instance_map ON (instance_map.product = product_code AND instance_map.family = instance_type_family)
Expand Down
8 changes: 8 additions & 0 deletions cid/builtin/core/data/queries/kpi/kpi_s3_storage_view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -163,6 +163,14 @@
, CASE WHEN s3_analytics_usage_quantity > 0 THEN 'in use' ELSE 'not in use' END AS s3_analytics_in_use
, CASE WHEN "s3_intelligent-tiering_storage_usage_quantity" > 0 THEN 'in use' ELSE 'not in use' END AS s3_int_in_use
, s3_standard_storage_cost * s3_standard_savings AS s3_standard_storage_potential_savings
-->>SAVINGS: estimate for non-standard, currently lumped into one group from IT to Glacier, based on the current KPI method for potential
, (("s3_standard-ia_storage_cost" +
"s3_onezone-ia_storage_cost" +
"s3_intelligent-tiering_storage_cost" +
s3_glacier_instant_retrieval_storage_cost +
s3_glacier_flexible_retrieval_storage_cost +
s3_glacier_deep_archive_storage_storage_cost) / (1 - s3_standard_savings)) * s3_standard_savings s3_storage_current_savings
--<<SAVINGS
, s3_all_cost
, s3_all_storage_cost
, s3_all_storage_usage_quantity
Expand Down
Loading
Loading