AWS Cost Management

These are queries for AWS Services under the AWS Cost Management product family .

Use the clipboard in the top right of the text boxes below to copy all of the text to be pasted.

CUR Query Library uses placeholder variables, indicated by a dollar sign and curly braces (${ }). ${table_name} and ${date_filter} are common placeholder variables used throughout CUR Query Library, which must be replaced before a query will run. For example, if your CUR table is called cur_table and is in a database called cur_db, you would replace ${table_name} with cur_db.cur_table. For ${date_filter}, you have multiple options. See Filtering by Date in the CUR Query Library Help section for additional details.

Table of Contents

AWS Marketplace

Query Description

This query provides AWS Marketplace subscription costs including subscription product name, associated linked account, and monthly total unblended cost. This query includes tax, however this can be filtered out in the WHERE clause. Please refer to the CUR Query Library Helpers section for assistance.

Pricing

Please refer to the AWS Marketplace FAQ .

Download SQL File

Link to Code

Copy Query

SELECT 
  bill_payer_account_id,
  line_item_usage_account_id,
  CASE line_item_usage_start_date
    WHEN NULL THEN DATE_FORMAT(DATE_PARSE(CONCAT(SPLIT_PART('${table_name}','_',5),'01'),'%Y%m%d'),'%Y-%m-01') 
    ELSE DATE_FORMAT(line_item_usage_start_date,'%Y-%m-01') 
  END AS case_line_item_usage_start_time,
  bill_billing_entity,
  product_product_name,
SUM(CAST(line_item_unblended_cost AS DECIMAL(16,8))) AS sum_line_item_unblended_cost
FROM 
  ${table_name} 
WHERE 
  ${date_filter} 
  AND bill_billing_entity = 'AWS Marketplace'
GROUP BY 
  bill_payer_account_id,
  line_item_usage_account_id,
  3, --refers to case_line_item_usage_start_time,
  bill_billing_entity,
  product_product_name
ORDER BY 
  case_line_item_usage_start_time ASC,
  sum_line_item_unblended_cost DESC;

Back to Table of Contents

Refund and Credit Detail

Query Description

This query provides a list of refunds and credits issued. Output is grouped by payer, linked account, month, line item type, service, and line item description. This allows for analysis of refunds and credits along any of these grouped dimensions. For example, “what refunds or credits were issued to account 111122223333 for service ABC in January 2022?” or “what was the total refund issued across all accounts for payer 444455556666 with line item description XYZ?”

Download SQL File

Link to Code

Copy Query

SELECT
  bill_payer_account_id,
  line_item_usage_account_id, 
  DATE_TRUNC('month',line_item_usage_start_date) as month_line_item_usage_start_date,
  line_item_line_item_type,
   CASE
    WHEN (bill_billing_entity = 'AWS Marketplace' AND line_item_line_item_type NOT LIKE '%Discount%') THEN product_product_name
    WHEN (product_servicecode = '') THEN line_item_product_code
    ELSE product_servicecode
  END case_service,
  line_item_line_item_description,
  SUM(line_item_unblended_cost) AS sum_line_item_unblended_cost
FROM
  ${tableName}
WHERE
  ${date_filter}
  AND line_item_unblended_cost < 0
  AND line_item_line_item_type <> 'SavingsPlanNegation'
GROUP BY
  bill_payer_account_id,
  line_item_usage_account_id, 
  DATE_TRUNC('month',line_item_usage_start_date),
  line_item_line_item_type,
  5, --refers to case_service
  line_item_line_item_description
ORDER BY
  month_line_item_usage_start_date ASC,
  sum_line_item_unblended_cost ASC;

Back to Table of Contents

Reservation Savings

Query Description

This query provides an aggregated report of savings from purchased reservations across multiple services - EC2, Elasticache, OpenSearch (formerly Amazon ElasticSearch), and RDS. This is similar to what can be found in Cost Explorer Reservation Utilization reports, except aggregated across all services offering reservations, allowing for easier organizational reporting on total savings. Output can be used to identify savings per specific reservation ARN, as well as savings per service, savings per linked account, savings per region, and savings per specific instance/node type.

Pricing

Please refer to the relevant service reservation pricing page.

Download SQL File

Link to Code

Copy Query

SELECT
  bill_payer_account_id,
  line_item_usage_account_id,
  DATE_FORMAT(line_item_usage_start_date,'%Y-%m') AS month_line_item_usage_start_date,
  line_item_product_code,
  reservation_reservation_a_r_n,
  SPLIT_PART(line_item_usage_type,':', 2) AS split_line_item_usage_type,
  SPLIT_PART(reservation_reservation_a_r_n,':', 4) AS split_product_region, -- split ARN for region due to product_region inconsistencies
  SUM(CAST(pricing_public_on_demand_cost AS DECIMAL (16,8))) AS sum_pricing_public_on_demand_cost,
  SUM(CASE
    WHEN line_item_line_item_type = 'DiscountedUsage' THEN reservation_effective_cost
    WHEN line_item_line_item_type = 'RIFee' THEN reservation_unused_amortized_upfront_fee_for_billing_period + reservation_unused_recurring_fee
    WHEN line_item_line_item_type = 'Fee' AND reservation_reservation_a_r_n <> '' THEN 0
  END) AS sum_case_reservation_effective_cost,
  SUM(TRY_CAST(pricing_public_on_demand_cost AS DECIMAL(16, 8))) 
    - SUM(CASE
        WHEN line_item_line_item_type = 'DiscountedUsage' THEN reservation_effective_cost
        WHEN line_item_line_item_type = 'RIFee' THEN reservation_unused_amortized_upfront_fee_for_billing_period + reservation_unused_recurring_fee
        WHEN line_item_line_item_type = 'Fee' AND reservation_reservation_a_r_n <> '' THEN 0
      END) AS sum_case_reservation_net_savings
FROM
  ${table_name}
WHERE
  ${date_filter}
  AND line_item_product_code IN ('AmazonEC2','AmazonRedshift','AmazonRDS','AmazonES','AmazonElastiCache')  
  AND line_item_line_item_type IN ('Fee','RIFee','DiscountedUsage')
GROUP BY
  bill_payer_account_id,
  line_item_usage_account_id,
  DATE_FORMAT(line_item_usage_start_date,'%Y-%m'),
  line_item_product_code,
  reservation_reservation_a_r_n,
  SPLIT_PART(line_item_usage_type,':', 2),
  SPLIT_PART(reservation_reservation_a_r_n,':', 4)
ORDER BY
  month_line_item_usage_start_date,
  line_item_product_code,
  split_line_item_usage_type;

CUR queries are provided as is. We recommend validating your data by comparing it against your monthly bill and Cost Explorer prior to making any financial decisions. If you wish to provide feedback on these queries, there is an error, or you want to make a suggestion, please email: curquery@amazon.com