监控 BigQuery 预留
作为 BigQuery 管理员,您可以通过查看项目和预留槽使用量来监控项目中的预留,还可以查看基于容量的账单。
查看项目和预留槽使用量
您可以通过以下方式查看项目和预留槽使用量:
INFORMATION_SCHEMA视图。如需检索项目和预留用量信息,请查询INFORMATION_SCHEMA.JOBS*视图。INFORMATION_SCHEMA.JOBS*视图中的reservation_id字段包含预留名称。Google Cloud 控制台。 Google Cloud 控制台包含显示槽用量的图表。如需了解详情,请参阅使用管理资源图表。
审核日志。 使用审核日志查看有关槽用量的指标。
Jobs方法。使用JobsAPI 方法查看作业的槽用量指标。Cloud Monitoring。您可以使用 Cloud Monitoring 创建信息中心来监控分配的槽。借助 Cloud Monitoring 信息中心,您可以在每个预留和每种作业类型中查看相应预留中的所有项目的槽用量。如需详细了解 Cloud Monitoring 信息中心可用的指标,请参阅可用于直观呈现数据的指标。

查看基于容量的账单
如需实时查看基于容量的账单,请按以下步骤操作:
在 Google Cloud 控制台中,前往结算页面。
转到结算。
选择要查看其账单的结算账号项目。
前往报告部分,然后在过滤条件部分中执行以下操作:
- 在服务列表中,选择 BigQuery,然后选择所有适用的服务。
- 从 SKU 列表中选择所有 SKU。
预留费用归属
借助此功能,您可以将预留费用归因回所有使用了该预留的项目中的特定查询用量。此功能可为每个项目生成更准确的净费用。
所有 BigQuery Reservations API 客户的 Cloud Billing 数据中都有一个“分析槽归属”专列项。此专列项包含在结算页面和 Cloud Billing 导出中。
此专列项会显示每个项目所用槽时数。此操作不会产生任何费用,也不会影响您的账单总额。
审核日志
项目所有者的审核日志中会记录创建、删除和更新与 BigQuery 预留相关的资源的操作。如需了解详情,请参阅审核日志。
使用信息架构监控自动扩缩
您可以使用以下 SQL 脚本检查特定版本的计费槽秒数。您必须在创建预留所在的项目中运行这些脚本。第一个脚本显示 commitment_plan 涵盖的已结算广告插播时段秒数,而第二个脚本显示未涵盖在承诺中的已结算广告插播时段秒数。
您只需设置三个变量的值即可运行这些脚本:
start_timeend_timeedition_to_check
这些脚本需注意以下事项:
在数据保留期限结束时,系统会从信息架构视图中移除已删除的预留和容量承诺。指定最近的时间范围,该时间范围不包含已删除的预留和承诺,以获得正确的结果。
由于舍入误差,脚本的结果可能与账单不完全一致。
以下脚本按版本汇总自动扩缩槽。
展开即可查看用于按版本计算自动扩缩槽秒数的脚本。
SELECT edition, SUM(s.autoscale_current_slots) AS autoscale_slot_seconds FROM `region-us.INFORMATION_SCHEMA.RESERVATIONS_TIMELINE` m JOIN m.per_second_details s WHERE period_start BETWEEN '2025-09-28' AND '2025-09-29' GROUP BY edition ORDER BY edition
以下脚本按预留汇总自动扩缩槽。
展开即可查看用于按预留计算自动扩缩槽秒数的脚本。
select reservation_id, sum(s.autoscale_current_slots) as autoscale_slot_seconds from `region-us.INFORMATION_SCHEMA.RESERVATIONS_TIMELINE` m LEFT JOIN m.per_second_details s WHERE period_start between '2025-09-28' and '2025-09-29' group by reservation_id order by reservation_id
展开即可查看用于根据承诺计算槽秒数的脚本。
DECLARE start_time,end_time TIMESTAMP; DECLARE edition_to_check STRING; /* Google uses Pacific Time to calculate the billing period for all customers, regardless of their time zone. Use the following format if you want to match the billing report. Change the start_time and end_time values to match the desired window. */ /* The following three variables (start_time, end_time, and edition_to_check) are the only variables that you need to set in the script. During daylight savings time, the start_time and end_time variables should follow this format: 2024-02-20 00:00:00-08. */ SET start_time = "2023-07-20 00:00:00-07"; SET end_time = "2023-07-28 00:00:00-07"; SET edition_to_check = 'ENTERPRISE'; /* The following function returns the slot seconds for the time window between two capacity changes. For example, if there are 100 slots between (2023-06-01 10:00:00, 2023-06-01 11:00:00), then during that window the total slot seconds will be 100 * 3600. This script calculates a specific window (based on the variables defined above), which is why the following script includes script_start_timestamp_unix_millis and script_end_timestamp_unix_millis. */ CREATE TEMP FUNCTION GetSlotSecondsBetweenChanges( slots FLOAT64, range_begin_timestamp_unix_millis FLOAT64, range_end_timestamp_unix_millis FLOAT64, script_start_timestamp_unix_millis FLOAT64, script_end_timestamp_unix_millis FLOAT64) RETURNS INT64 LANGUAGE js AS r""" if (script_end_timestamp_unix_millis < range_begin_timestamp_unix_millis || script_start_timestamp_unix_millis > range_end_timestamp_unix_millis) { return 0; } var begin = Math.max(script_start_timestamp_unix_millis, range_begin_timestamp_unix_millis) var end = Math.min(script_end_timestamp_unix_millis, range_end_timestamp_unix_millis) return slots * Math.ceil((end - begin) / 1000.0) """; /* Sample CAPACITY_COMMITMENT_CHANGES data (unrelated columns ignored): +---------------------+------------------------+-----------------+--------+------------+--------+ | change_timestamp | capacity_commitment_id | commitment_plan | state | slot_count | action | +---------------------+------------------------+-----------------+--------+------------+--------+ | 2023-07-20 19:30:27 | 12954109101902401697 | ANNUAL | ACTIVE | 100 | CREATE | | 2023-07-27 22:29:21 | 11445583810276646822 | FLEX | ACTIVE | 100 | CREATE | | 2023-07-27 23:10:06 | 7341455530498381779 | MONTHLY | ACTIVE | 100 | CREATE | | 2023-07-27 23:11:06 | 7341455530498381779 | FLEX | ACTIVE | 100 | UPDATE | The last row indicates a special change from MONTHLY to FLEX, which happens because of commercial migration. */ WITH /* Information containing which commitment might have plan updated (e.g. renewal or commercial migration). For example: +------------------------+------------------+--------------------+--------+------------+--------+-----------+----------------------------+ | change_timestamp | capacity_commitment_id | commitment_plan | state | slot_count | action | next_plan | next_plan_change_timestamp | +---------------------+------------------------+-----------------+--------+------------+--------+-----------+----------------------------+ | 2023-07-20 19:30:27 | 12954109101902401697 | ANNUAL | ACTIVE | 100 | CREATE | ANNUAL | 2023-07-20 19:30:27 | | 2023-07-27 22:29:21 | 11445583810276646822 | FLEX | ACTIVE | 100 | CREATE | FLEX | 2023-07-27 22:29:21 | | 2023-07-27 23:10:06 | 7341455530498381779 | MONTHLY | ACTIVE | 100 | CREATE | FLEX | 2023-07-27 23:11:06 | | 2023-07-27 23:11:06 | 7341455530498381779 | FLEX | ACTIVE | 100 | UPDATE | FLEX | 2023-07-27 23:11:06 | */ commitments_with_next_plan AS ( SELECT *, IFNULL( LEAD(commitment_plan) OVER ( PARTITION BY capacity_commitment_id ORDER BY change_timestamp ASC ), commitment_plan) next_plan, IFNULL( LEAD(change_timestamp) OVER ( PARTITION BY capacity_commitment_id ORDER BY change_timestamp ASC ), change_timestamp) next_plan_change_timestamp FROM `region-us.INFORMATION_SCHEMA.CAPACITY_COMMITMENT_CHANGES_BY_PROJECT` ), /* Insert a 'DELETE' action for those with updated plans. The FLEX commitment '7341455530498381779' is has no 'CREATE' action, and is instead labeled as an 'UPDATE' action. For example: +---------------------+------------------------+-----------------+--------+------------+--------+ | change_timestamp | capacity_commitment_id | commitment_plan | state | slot_count | action | +---------------------+------------------------+-----------------+--------+------------+--------+ | 2023-07-20 19:30:27 | 12954109101902401697 | ANNUAL | ACTIVE | 100 | CREATE | | 2023-07-27 22:29:21 | 11445583810276646822 | FLEX | ACTIVE | 100 | CREATE | | 2023-07-27 23:10:06 | 7341455530498381779 | MONTHLY | ACTIVE | 100 | CREATE | | 2023-07-27 23:11:06 | 7341455530498381779 | FLEX | ACTIVE | 100 | UPDATE | | 2023-07-27 23:11:06 | 7341455530498381779 | MONTHLY | ACTIVE | 100 | DELETE | */ capacity_changes_with_additional_deleted_event_for_changed_plan AS ( SELECT next_plan_change_timestamp AS change_timestamp, project_id, project_number, capacity_commitment_id, commitment_plan, state, slot_count, 'DELETE' AS action, commitment_start_time, commitment_end_time, failure_status, renewal_plan, user_email, edition, is_flat_rate, FROM commitments_with_next_plan WHERE commitment_plan <> next_plan UNION ALL SELECT * FROM `region-us.INFORMATION_SCHEMA.CAPACITY_COMMITMENT_CHANGES_BY_PROJECT` ), /* The committed_slots change the history. For example: +---------------------+------------------------+------------------+-----------------+ | change_timestamp | capacity_commitment_id | slot_count_delta | commitment_plan | +---------------------+------------------------+------------------+-----------------+ | 2023-07-20 19:30:27 | 12954109101902401697 | 100 | ANNUAL | | 2023-07-27 22:29:21 | 11445583810276646822 | 100 | FLEX | | 2023-07-27 23:10:06 | 7341455530498381779 | 100 | MONTHLY | | 2023-07-27 23:11:06 | 7341455530498381779 | -100 | MONTHLY | | 2023-07-27 23:11:06 | 7341455530498381779 | 100 | FLEX | */ capacity_commitment_slot_data AS ( SELECT change_timestamp, capacity_commitment_id, CASE WHEN action = "CREATE" OR action = "UPDATE" THEN IFNULL( IF( LAG(action) OVER ( PARTITION BY capacity_commitment_id ORDER BY change_timestamp ASC, action ASC ) IN UNNEST(['CREATE', 'UPDATE']), slot_count - LAG(slot_count) OVER ( PARTITION BY capacity_commitment_id ORDER BY change_timestamp ASC, action ASC ), slot_count), slot_count) ELSE IF( LAG(action) OVER (PARTITION BY capacity_commitment_id ORDER BY change_timestamp ASC, action ASC) IN UNNEST(['CREATE', 'UPDATE']), -1 * slot_count, 0) END AS slot_count_delta, commitment_plan FROM capacity_changes_with_additional_deleted_event_for_changed_plan WHERE state = "ACTIVE" AND edition = edition_to_check AND change_timestamp <= end_time ), /* The total_committed_slots history for each plan. For example: +---------------------+---------------+-----------------+ | change_timestamp | capacity_slot | commitment_plan | +---------------------+---------------+-----------------+ | 2023-07-20 19:30:27 | 100 | ANNUAL | | 2023-07-27 22:29:21 | 100 | FLEX | | 2023-07-27 23:10:06 | 100 | MONTHLY | | 2023-07-27 23:11:06 | 0 | MONTHLY | | 2023-07-27 23:11:06 | 200 | FLEX | */ running_capacity_commitment_slot_data AS ( SELECT change_timestamp, SUM(slot_count_delta) OVER ( PARTITION BY commitment_plan ORDER BY change_timestamp RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW ) AS capacity_slot, commitment_plan, FROM capacity_commitment_slot_data ), /* The slot_seconds between each changes, partitioned by each plan. For example: +---------------------+--------------+-----------------+ | change_timestamp | slot_seconds | commitment_plan | +---------------------+--------------+-----------------+ | 2023-07-20 19:30:27 | 64617300 | ANNUAL | | 2023-07-27 22:29:21 | 250500 | FLEX | | 2023-07-27 23:10:06 | 6000 | MONTHLY | | 2023-07-27 23:11:06 | 0 | MONTHLY | | 2023-07-27 23:11:06 | 5626800 | FLEX | */ slot_seconds_data AS ( SELECT change_timestamp, GetSlotSecondsBetweenChanges( capacity_slot, UNIX_MILLIS(change_timestamp), UNIX_MILLIS( IFNULL( LEAD(change_timestamp) OVER (PARTITION BY commitment_plan ORDER BY change_timestamp ASC), CURRENT_TIMESTAMP())), UNIX_MILLIS(start_time), UNIX_MILLIS(end_time)) AS slot_seconds, commitment_plan, FROM running_capacity_commitment_slot_data WHERE change_timestamp <= end_time ) /* The final result is similar to the following: +-----------------+--------------------+ | commitment_plan | total_slot_seconds | +-----------------+--------------------+ | ANNUAL | 64617300 | | MONTHLY | 6000 | | FLEX | 5877300 | */ SELECT commitment_plan, SUM(slot_seconds) AS total_slot_seconds FROM slot_seconds_data GROUP BY commitment_plan
以下脚本会检查承诺未涵盖的特定版本的槽用量。此用量包含两种类型的槽:承诺未涵盖的扩缩槽和基准槽。
展开即可查看用于计算承诺未涵盖的槽秒数的脚本
/* This script has several parts: 1. Calculate the baseline and scaled slots for reservations 2. Calculate the committed slots 3. Join the two results above to calculate the baseline not covered by committed slots 4. Aggregate the number */ -- variables DECLARE start_time, end_time TIMESTAMP; DECLARE edition_to_check STRING; /* Google uses Pacific Time to calculate the billing period for all customers, regardless of their time zone. Use the following format if you want to match the billing report. Change the start_time and end_time values to match the desired window. */ /* The following three variables (start_time, end_time, and edition_to_check) are the only variables that you need to set in the script. During daylight savings time, the start_time and end_time variables should follow this format: 2024-02-20 00:00:00-08. */ SET start_time = "2023-07-20 00:00:00-07"; SET end_time = "2023-07-28 00:00:00-07"; SET edition_to_check = 'ENTERPRISE'; /* The following function returns the slot seconds for the time window between two capacity changes. For example, if there are 100 slots between (2023-06-01 10:00:00, 2023-06-01 11:00:00), then during that window the total slot seconds will be 100 * 3600. This script calculates a specific window (based on the variables defined above), which is why the following script includes script_start_timestamp_unix_millis and script_end_timestamp_unix_millis. */ CREATE TEMP FUNCTION GetSlotSecondsBetweenChanges( slots FLOAT64, range_begin_timestamp_unix_millis FLOAT64, range_end_timestamp_unix_millis FLOAT64, script_start_timestamp_unix_millis FLOAT64, script_end_timestamp_unix_millis FLOAT64) RETURNS INT64 LANGUAGE js AS r""" if (script_end_timestamp_unix_millis < range_begin_timestamp_unix_millis || script_start_timestamp_unix_millis > range_end_timestamp_unix_millis) { return 0; } var begin = Math.max(script_start_timestamp_unix_millis, range_begin_timestamp_unix_millis) var end = Math.min(script_end_timestamp_unix_millis, range_end_timestamp_unix_millis) return slots * Math.ceil((end - begin) / 1000.0) """; /* Sample RESERVATION_CHANGES data (unrelated columns ignored): +---------------------+------------------+--------+---------------+---------------+ | change_timestamp | reservation_name | action | slot_capacity | current_slots | +---------------------+------------------+--------+---------------+---------------+ | 2023-07-27 22:24:15 | res1 | CREATE | 300 | 0 | | 2023-07-27 22:25:21 | res1 | UPDATE | 300 | 180 | | 2023-07-27 22:39:14 | res1 | UPDATE | 300 | 100 | | 2023-07-27 22:40:20 | res2 | CREATE | 300 | 0 | | 2023-07-27 22:54:18 | res2 | UPDATE | 300 | 120 | | 2023-07-27 22:55:23 | res1 | UPDATE | 300 | 0 | Sample CAPACITY_COMMITMENT_CHANGES data (unrelated columns ignored): +---------------------+------------------------+-----------------+--------+------------+--------+ | change_timestamp | capacity_commitment_id | commitment_plan | state | slot_count | action | +---------------------+------------------------+-----------------+--------+------------+--------+ | 2023-07-20 19:30:27 | 12954109101902401697 | ANNUAL | ACTIVE | 100 | CREATE | | 2023-07-27 22:29:21 | 11445583810276646822 | FLEX | ACTIVE | 100 | CREATE | | 2023-07-27 23:10:06 | 7341455530498381779 | MONTHLY | ACTIVE | 100 | CREATE | */ WITH /* The scaled_slots & baseline change history: +---------------------+------------------+------------------------------+---------------------+ | change_timestamp | reservation_name | autoscale_current_slot_delta | baseline_slot_delta | +---------------------+------------------+------------------------------+---------------------+ | 2023-07-27 22:24:15 | res1 | 0 | 300 | | 2023-07-27 22:25:21 | res1 | 180 | 0 | | 2023-07-27 22:39:14 | res1 | -80 | 0 | | 2023-07-27 22:40:20 | res2 | 0 | 300 | | 2023-07-27 22:54:18 | res2 | 120 | 0 | | 2023-07-27 22:55:23 | res1 | -100 | 0 | */ reservation_slot_data AS ( SELECT change_timestamp, reservation_name, CASE action WHEN "CREATE" THEN autoscale.current_slots WHEN "UPDATE" THEN IFNULL( autoscale.current_slots - LAG(autoscale.current_slots) OVER ( PARTITION BY project_id, reservation_name ORDER BY change_timestamp ASC, action ASC ), IFNULL( autoscale.current_slots, IFNULL( -1 * LAG(autoscale.current_slots) OVER ( PARTITION BY project_id, reservation_name ORDER BY change_timestamp ASC, action ASC ), 0))) WHEN "DELETE" THEN IF( LAG(action) OVER ( PARTITION BY project_id, reservation_name ORDER BY change_timestamp ASC, action ASC ) IN UNNEST(['CREATE', 'UPDATE']), -1 * autoscale.current_slots, 0) END AS autoscale_current_slot_delta, CASE action WHEN "CREATE" THEN slot_capacity WHEN "UPDATE" THEN IFNULL( slot_capacity - LAG(slot_capacity) OVER ( PARTITION BY project_id, reservation_name ORDER BY change_timestamp ASC, action ASC ), IFNULL( slot_capacity, IFNULL( -1 * LAG(slot_capacity) OVER ( PARTITION BY project_id, reservation_name ORDER BY change_timestamp ASC, action ASC ), 0))) WHEN "DELETE" THEN IF( LAG(action) OVER ( PARTITION BY project_id, reservation_name ORDER BY change_timestamp ASC, action ASC ) IN UNNEST(['CREATE', 'UPDATE']), -1 * slot_capacity, 0) END AS baseline_slot_delta, FROM `region-us.INFORMATION_SCHEMA.RESERVATION_CHANGES` WHERE edition = edition_to_check AND change_timestamp <= end_time ), -- Convert the above to running total /* +---------------------+-------------------------+----------------+ | change_timestamp | autoscale_current_slots | baseline_slots | +---------------------+-------------------------+----------------+ | 2023-07-27 22:24:15 | 0 | 300 | | 2023-07-27 22:25:21 | 180 | 300 | | 2023-07-27 22:39:14 | 100 | 300 | | 2023-07-27 22:40:20 | 100 | 600 | | 2023-07-27 22:54:18 | 220 | 600 | | 2023-07-27 22:55:23 | 120 | 600 | */ running_reservation_slot_data AS ( SELECT change_timestamp, SUM(autoscale_current_slot_delta) OVER (ORDER BY change_timestamp RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS autoscale_current_slots, SUM(baseline_slot_delta) OVER (ORDER BY change_timestamp RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS baseline_slots, FROM reservation_slot_data ), /* The committed_slots change history. For example: +---------------------+------------------------+------------------+ | change_timestamp | capacity_commitment_id | slot_count_delta | +---------------------+------------------------+------------------+ | 2023-07-20 19:30:27 | 12954109101902401697 | 100 | | 2023-07-27 22:29:21 | 11445583810276646822 | 100 | | 2023-07-27 23:10:06 | 7341455530498381779 | 100 | */ capacity_commitment_slot_data AS ( SELECT change_timestamp, capacity_commitment_id, CASE WHEN action = "CREATE" OR action = "UPDATE" THEN IFNULL( IF( LAG(action) OVER ( PARTITION BY capacity_commitment_id ORDER BY change_timestamp ASC, action ASC ) IN UNNEST(['CREATE', 'UPDATE']), slot_count - LAG(slot_count) OVER ( PARTITION BY capacity_commitment_id ORDER BY change_timestamp ASC, action ASC ), slot_count), slot_count) ELSE IF( LAG(action) OVER (PARTITION BY capacity_commitment_id ORDER BY change_timestamp ASC, action ASC) IN UNNEST(['CREATE', 'UPDATE']), -1 * slot_count, 0) END AS slot_count_delta FROM `region-us.INFORMATION_SCHEMA.CAPACITY_COMMITMENT_CHANGES_BY_PROJECT` WHERE state = "ACTIVE" AND edition = edition_to_check AND change_timestamp <= end_time ), /* The total_committed_slots history. For example: +---------------------+---------------+ | change_timestamp | capacity_slot | +---------------------+---------------+ | 2023-07-20 19:30:27 | 100 | | 2023-07-27 22:29:21 | 200 | | 2023-07-27 23:10:06 | 300 | */ running_capacity_commitment_slot_data AS ( SELECT change_timestamp, SUM(slot_count_delta) OVER (ORDER BY change_timestamp RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS capacity_slot FROM capacity_commitment_slot_data ), /* Add next_change_timestamp to the above data, which will be used when joining with reservation data. For example: +---------------------+-----------------------+---------------+ | change_timestamp | next_change_timestamp | capacity_slot | +---------------------+-----------------------+---------------+ | 2023-07-20 19:30:27 | 2023-07-27 22:29:21 | 100 | | 2023-07-27 22:29:21 | 2023-07-27 23:10:06 | 200 | | 2023-07-27 23:10:06 | 2023-07-31 00:14:37 | 300 | */ running_capacity_commitment_slot_data_with_next_change AS ( SELECT change_timestamp, IFNULL(LEAD(change_timestamp) OVER (ORDER BY change_timestamp ASC), CURRENT_TIMESTAMP()) AS next_change_timestamp, capacity_slot FROM running_capacity_commitment_slot_data ), /* Whenever we have a change in reservations or commitments, the scaled_slots_and_baseline_not_covered_by_commitments will be changed. Hence we get a collection of all the change_timestamp from both tables. +---------------------+ | change_timestamp | +---------------------+ | 2023-07-20 19:30:27 | | 2023-07-27 22:24:15 | | 2023-07-27 22:25:21 | | 2023-07-27 22:29:21 | | 2023-07-27 22:39:14 | | 2023-07-27 22:40:20 | | 2023-07-27 22:54:18 | | 2023-07-27 22:55:23 | | 2023-07-27 23:10:06 | */ merged_timestamp AS ( SELECT change_timestamp FROM running_reservation_slot_data UNION DISTINCT SELECT change_timestamp FROM running_capacity_commitment_slot_data ), /* Change running reservation-slots and make sure we have one row when commitment changes. +---------------------+-------------------------+----------------+ | change_timestamp | autoscale_current_slots | baseline_slots | +---------------------+-------------------------+----------------+ | 2023-07-20 19:30:27 | 0 | 0 | | 2023-07-27 22:24:15 | 0 | 300 | | 2023-07-27 22:25:21 | 180 | 300 | | 2023-07-27 22:29:21 | 180 | 300 | | 2023-07-27 22:39:14 | 100 | 300 | | 2023-07-27 22:40:20 | 100 | 600 | | 2023-07-27 22:54:18 | 220 | 600 | | 2023-07-27 22:55:23 | 120 | 600 | | 2023-07-27 23:10:06 | 120 | 600 | */ running_reservation_slot_data_with_merged_timestamp AS ( SELECT change_timestamp, IFNULL( autoscale_current_slots, IFNULL( LAST_VALUE(autoscale_current_slots IGNORE NULLS) OVER (ORDER BY change_timestamp ASC), 0)) AS autoscale_current_slots, IFNULL( baseline_slots, IFNULL(LAST_VALUE(baseline_slots IGNORE NULLS) OVER (ORDER BY change_timestamp ASC), 0)) AS baseline_slots FROM running_reservation_slot_data RIGHT JOIN merged_timestamp USING (change_timestamp) ), /* Join the above, so that we will know the number for baseline not covered by commitments. +---------------------+-----------------------+-------------------------+------------------------------------+ | change_timestamp | next_change_timestamp | autoscale_current_slots | baseline_not_covered_by_commitment | +---------------------+-----------------------+-------------------------+------------------------------------+ | 2023-07-20 19:30:27 | 2023-07-27 22:24:15 | 0 | 0 | | 2023-07-27 22:24:15 | 2023-07-27 22:25:21 | 0 | 200 | | 2023-07-27 22:25:21 | 2023-07-27 22:29:21 | 180 | 200 | | 2023-07-27 22:29:21 | 2023-07-27 22:39:14 | 180 | 100 | | 2023-07-27 22:39:14 | 2023-07-27 22:40:20 | 100 | 100 | | 2023-07-27 22:40:20 | 2023-07-27 22:54:18 | 100 | 400 | | 2023-07-27 22:54:18 | 2023-07-27 22:55:23 | 220 | 400 | | 2023-07-27 22:55:23 | 2023-07-27 23:10:06 | 120 | 400 | | 2023-07-27 23:10:06 | 2023-07-31 00:16:07 | 120 | 300 | */ scaled_slots_and_baseline_not_covered_by_commitments AS ( SELECT r.change_timestamp, IFNULL(LEAD(r.change_timestamp) OVER (ORDER BY r.change_timestamp ASC), CURRENT_TIMESTAMP()) AS next_change_timestamp, r.autoscale_current_slots, IF( r.baseline_slots - IFNULL(c.capacity_slot, 0) > 0, r.baseline_slots - IFNULL(c.capacity_slot, 0), 0) AS baseline_not_covered_by_commitment FROM running_reservation_slot_data_with_merged_timestamp r LEFT JOIN running_capacity_commitment_slot_data_with_next_change c ON r.change_timestamp >= c.change_timestamp AND r.change_timestamp < c.next_change_timestamp ), /* The slot_seconds between each changes. For example: +---------------------+--------------------+ | change_timestamp | slot_seconds | +---------------------+--------------+ | 2023-07-20 19:30:27 | 0 | | 2023-07-27 22:24:15 | 13400 | | 2023-07-27 22:25:21 | 91580 | | 2023-07-27 22:29:21 | 166320 | | 2023-07-27 22:39:14 | 13200 | | 2023-07-27 22:40:20 | 419500 | | 2023-07-27 22:54:18 | 40920 | | 2023-07-27 22:55:23 | 459160 | | 2023-07-27 23:10:06 | 11841480 | */ slot_seconds_data AS ( SELECT change_timestamp, GetSlotSecondsBetweenChanges( autoscale_current_slots + baseline_not_covered_by_commitment, UNIX_MILLIS(change_timestamp), UNIX_MILLIS(next_change_timestamp), UNIX_MILLIS(start_time), UNIX_MILLIS(end_time)) AS slot_seconds FROM scaled_slots_and_baseline_not_covered_by_commitments WHERE change_timestamp <= end_time AND next_change_timestamp > start_time ) /* Final result for this example: +--------------------+ | total_slot_seconds | +--------------------+ | 13045560 | */ SELECT SUM(slot_seconds) AS total_slot_seconds FROM slot_seconds_data
后续步骤
- 了解容量承诺方案。
- 了解如何使用管理资源图表。
- 了解 BigQuery 定价。