-
Notifications
You must be signed in to change notification settings - Fork 103
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Add aws_cost_by_region_monthly table (#2310)
- Loading branch information
Showing
3 changed files
with
339 additions
and
1 deletion.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,108 @@ | ||
package aws | ||
|
||
import ( | ||
"context" | ||
"strings" | ||
"time" | ||
|
||
"github.com/aws/aws-sdk-go-v2/aws" | ||
"github.com/aws/aws-sdk-go-v2/service/costexplorer" | ||
"github.com/aws/aws-sdk-go-v2/service/costexplorer/types" | ||
|
||
"github.com/turbot/steampipe-plugin-sdk/v5/grpc/proto" | ||
"github.com/turbot/steampipe-plugin-sdk/v5/plugin" | ||
"github.com/turbot/steampipe-plugin-sdk/v5/plugin/transform" | ||
) | ||
|
||
func tableAwsCostByRegionMonthly(_ context.Context) *plugin.Table { | ||
return &plugin.Table{ | ||
Name: "aws_cost_by_region_monthly", | ||
Description: "AWS Cost Explorer - Cost by Region (Monthly)", | ||
List: &plugin.ListConfig{ | ||
Hydrate: listCostByRegionMonthly, | ||
Tags: map[string]string{"service": "ce", "action": "GetCostAndUsage"}, | ||
KeyColumns: plugin.KeyColumnSlice{ | ||
{Name: "region", Operators: []string{"=", "<>"}, Require: plugin.Optional}, | ||
}, | ||
}, | ||
Columns: costExplorerColumns([]*plugin.Column{ | ||
{ | ||
Name: "region", | ||
Description: "The name of the AWS region.", | ||
Type: proto.ColumnType_STRING, | ||
Transform: transform.FromField("Dimension1"), | ||
}, | ||
}), | ||
} | ||
} | ||
|
||
//// LIST FUNCTION | ||
|
||
func listCostByRegionMonthly(ctx context.Context, d *plugin.QueryData, _ *plugin.HydrateData) (interface{}, error) { | ||
params := buildCostByRegionInput("MONTHLY", d) | ||
return streamCostAndUsage(ctx, d, params) | ||
} | ||
|
||
func buildCostByRegionInput(granularity string, d *plugin.QueryData) *costexplorer.GetCostAndUsageInput { | ||
timeFormat := "2006-01-02" | ||
if granularity == "HOURLY" { | ||
timeFormat = "2006-01-02T15:04:05Z" | ||
} | ||
|
||
endTime := time.Now().Format(timeFormat) | ||
startTime := getCEStartDateForGranularity(granularity).Format(timeFormat) | ||
|
||
params := &costexplorer.GetCostAndUsageInput{ | ||
TimePeriod: &types.DateInterval{ | ||
Start: aws.String(startTime), | ||
End: aws.String(endTime), | ||
}, | ||
Granularity: types.Granularity(granularity), | ||
Metrics: AllCostMetrics(), | ||
GroupBy: []types.GroupDefinition{ | ||
{ | ||
Type: types.GroupDefinitionType("DIMENSION"), | ||
Key: aws.String("REGION"), | ||
}, | ||
}, | ||
} | ||
|
||
var filters []types.Expression | ||
|
||
for _, keyQual := range d.Table.List.KeyColumns { | ||
filterQual := d.Quals[keyQual.Name] | ||
if filterQual == nil { | ||
continue | ||
} | ||
for _, qual := range filterQual.Quals { | ||
if qual.Value != nil { | ||
value := qual.Value | ||
switch qual.Operator { | ||
case "=": | ||
filter := types.Expression{} | ||
filter.Dimensions = &types.DimensionValues{} | ||
filter.Dimensions.Key = types.Dimension(strings.ToUpper(keyQual.Name)) | ||
filter.Dimensions.Values = []string{value.GetStringValue()} | ||
filters = append(filters, filter) | ||
case "<>": | ||
filter := types.Expression{} | ||
filter.Not = &types.Expression{} | ||
filter.Not.Dimensions = &types.DimensionValues{} | ||
filter.Not.Dimensions.Key = types.Dimension(strings.ToUpper(keyQual.Name)) | ||
filter.Not.Dimensions.Values = []string{value.GetStringValue()} | ||
filters = append(filters, filter) | ||
} | ||
} | ||
} | ||
} | ||
|
||
if len(filters) > 1 { | ||
params.Filter = &types.Expression{ | ||
And: filters, | ||
} | ||
} else if len(filters) == 1 { | ||
params.Filter = &(filters[0]) | ||
} | ||
|
||
return params | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,229 @@ | ||
--- | ||
title: "Steampipe Table: aws_cost_by_region_monthly - Query AWS Cost Explorer Service using SQL" | ||
description: "Allows users to query AWS Cost Explorer Service for monthly cost breakdown by region. This table provides details such as the region name, the cost associated with it, and the currency code." | ||
--- | ||
|
||
# Table: aws_cost_by_region_monthly - Query AWS Cost Explorer region using SQL | ||
|
||
The AWS Cost Explorer region provides detailed information about your AWS costs, enabling you to analyze your costs and usage over time. You can use it to identify trends, isolate cost drivers, and detect anomalies. With SQL queries, you can retrieve monthly cost data specific to each AWS region. | ||
|
||
## Table Usage Guide | ||
|
||
The `aws_cost_by_region_monthly` table in Steampipe provides you with information about the monthly cost breakdown by region within AWS Cost Explorer. This table allows you, as a financial analyst, DevOps engineer, or other stakeholder, to query cost-specific details, including the region name, the cost associated with it, and the currency code. You can utilize this table to gather insights on cost management, such as tracking AWS expenses, identifying cost trends, and auditing. The schema outlines the various attributes of the cost information, including the region name, cost, and currency code. | ||
|
||
Amazon Cost Explorer helps you visualize, understand, and manage your AWS costs and usage. The `aws_cost_by_region_monthly` table provides you with a simplified view of cost for regions in your account (or all linked accounts when run against the organization master), summarized by month, for the last year. | ||
|
||
**Important Notes** | ||
|
||
- The [pricing for the Cost Explorer API](https://aws.amazon.com/aws-cost-management/pricing/) is per API request - Each request you make will incur a cost of $0.01. | ||
|
||
## Examples | ||
|
||
### Basic info | ||
Explore which AWS regions have the highest costs over time. This query is useful in identifying potential areas for cost reduction through region optimization or consolidation. | ||
|
||
```sql+postgres | ||
select | ||
region, | ||
period_start, | ||
blended_cost_amount::numeric::money, | ||
unblended_cost_amount::numeric::money, | ||
amortized_cost_amount::numeric::money, | ||
net_unblended_cost_amount::numeric::money, | ||
net_amortized_cost_amount::numeric::money | ||
from | ||
aws_cost_by_region_monthly | ||
order by | ||
region, | ||
period_start; | ||
``` | ||
|
||
```sql+sqlite | ||
select | ||
region, | ||
period_start, | ||
cast(blended_cost_amount as decimal), | ||
cast(unblended_cost_amount as decimal), | ||
cast(amortized_cost_amount as decimal), | ||
cast(net_unblended_cost_amount as decimal), | ||
cast(net_amortized_cost_amount as decimal) | ||
from | ||
aws_cost_by_region_monthly | ||
order by | ||
region, | ||
period_start; | ||
``` | ||
|
||
|
||
|
||
### Min, Max, and average monthly unblended_cost_amount by region | ||
Explore which AWS regions have the lowest, highest, and average monthly costs, providing a clear understanding of your AWS expenditure. This can help in budgeting and identifying regions that may be costing more than expected. | ||
|
||
```sql+postgres | ||
select | ||
region, | ||
min(unblended_cost_amount)::numeric::money as min, | ||
max(unblended_cost_amount)::numeric::money as max, | ||
avg(unblended_cost_amount)::numeric::money as average | ||
from | ||
aws_cost_by_region_monthly | ||
group by | ||
region | ||
order by | ||
region; | ||
``` | ||
|
||
```sql+sqlite | ||
select | ||
region, | ||
min(unblended_cost_amount) as min, | ||
max(unblended_cost_amount) as max, | ||
avg(unblended_cost_amount) as average | ||
from | ||
aws_cost_by_region_monthly | ||
group by | ||
region | ||
order by | ||
region; | ||
``` | ||
|
||
### Top 10 most expensive region (by average monthly unblended_cost_amount) | ||
Discover the segments that are incurring the highest average monthly costs on your AWS account. This information can be crucial for budgeting and cost management strategies, helping you to identify areas where expenses can be reduced. | ||
|
||
```sql+postgres | ||
select | ||
region, | ||
sum(unblended_cost_amount)::numeric::money as sum, | ||
avg(unblended_cost_amount)::numeric::money as average | ||
from | ||
aws_cost_by_region_monthly | ||
group by | ||
region | ||
order by | ||
average desc | ||
limit 10; | ||
``` | ||
|
||
```sql+sqlite | ||
select | ||
region, | ||
sum(unblended_cost_amount) as sum, | ||
avg(unblended_cost_amount) as average | ||
from | ||
aws_cost_by_region_monthly | ||
group by | ||
region | ||
order by | ||
average desc | ||
limit 10; | ||
``` | ||
|
||
|
||
### Top 10 most expensive region (by total monthly unblended_cost_amount) | ||
This query helps to pinpoint the top 10 most costly regions in terms of total monthly unblended cost. It is useful for gaining insights into where the majority of your AWS costs are coming from, allowing for more informed budgeting and cost management decisions. | ||
|
||
```sql+postgres | ||
select | ||
region, | ||
sum(unblended_cost_amount)::numeric::money as sum, | ||
avg(unblended_cost_amount)::numeric::money as average | ||
from | ||
aws_cost_by_region_monthly | ||
group by | ||
region | ||
order by | ||
sum desc | ||
limit 10; | ||
``` | ||
|
||
```sql+sqlite | ||
select | ||
region, | ||
sum(unblended_cost_amount) as sum, | ||
avg(unblended_cost_amount) as average | ||
from | ||
aws_cost_by_region_monthly | ||
group by | ||
region | ||
order by | ||
sum desc | ||
limit 10; | ||
``` | ||
|
||
|
||
### Ranked - Most expensive month (unblended_cost_amount) by region | ||
This query is designed to identify the most costly month for each region in terms of unblended costs. It can be useful for budgeting and cost management, helping to highlight areas where expenses may be unexpectedly high. | ||
|
||
```sql+postgres | ||
with ranked_costs as ( | ||
select | ||
region, | ||
period_start, | ||
unblended_cost_amount::numeric::money, | ||
rank() over(partition by region order by unblended_cost_amount desc) | ||
from | ||
aws_cost_by_region_monthly | ||
) | ||
select * from ranked_costs where rank = 1; | ||
``` | ||
|
||
```sql+sqlite | ||
Error: SQLite does not support the rank window function. | ||
``` | ||
|
||
### Month on month growth (unblended_cost_amount) by region | ||
Analyze your AWS monthly costs to understand the percentage change in expenditure for each region. This could be useful for identifying trends, managing budgets, and making strategic decisions about resource allocation. | ||
|
||
```sql+postgres | ||
with cost_data as ( | ||
select | ||
region, | ||
period_start, | ||
unblended_cost_amount as this_month, | ||
lag(unblended_cost_amount,-1) over(partition by region order by period_start desc) as previous_month | ||
from | ||
aws_cost_by_region_monthly | ||
) | ||
select | ||
region, | ||
period_start, | ||
this_month::numeric::money, | ||
previous_month::numeric::money, | ||
case | ||
when previous_month = 0 and this_month = 0 then 0 | ||
when previous_month = 0 then 999 | ||
else round((100 * ( (this_month - previous_month) / previous_month))::numeric, 2) | ||
end as percent_change | ||
from | ||
cost_data | ||
order by | ||
region, | ||
period_start; | ||
``` | ||
|
||
```sql+sqlite | ||
with cost_data as ( | ||
select | ||
region, | ||
period_start, | ||
unblended_cost_amount as this_month, | ||
lag(unblended_cost_amount,-1) over(partition by region order by period_start desc) as previous_month | ||
from | ||
aws_cost_by_region_monthly | ||
) | ||
select | ||
region, | ||
period_start, | ||
this_month, | ||
previous_month, | ||
case | ||
when previous_month = 0 and this_month = 0 then 0 | ||
when previous_month = 0 then 999 | ||
else round((100 * ( (this_month - previous_month) / previous_month)), 2) | ||
end as percent_change | ||
from | ||
cost_data | ||
order by | ||
region, | ||
period_start; | ||
``` |