-
Notifications
You must be signed in to change notification settings - Fork 248
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
[batch] Stop writing to v2 billing tables #13892
Merged
Merged
Changes from all commits
Commits
Show all changes
4 commits
Select commit
Hold shift + click to select a range
File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
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,120 @@ | ||
DELIMITER $$ | ||
|
||
DROP TRIGGER IF EXISTS attempts_after_update $$ | ||
CREATE TRIGGER attempts_after_update AFTER UPDATE ON attempts | ||
FOR EACH ROW | ||
BEGIN | ||
DECLARE job_cores_mcpu INT; | ||
DECLARE cur_billing_project VARCHAR(100); | ||
DECLARE msec_diff_rollup BIGINT; | ||
DECLARE cur_n_tokens INT; | ||
DECLARE rand_token INT; | ||
DECLARE cur_billing_date DATE; | ||
|
||
SELECT n_tokens INTO cur_n_tokens FROM globals LOCK IN SHARE MODE; | ||
SET rand_token = FLOOR(RAND() * cur_n_tokens); | ||
|
||
SELECT cores_mcpu INTO job_cores_mcpu FROM jobs | ||
WHERE batch_id = NEW.batch_id AND job_id = NEW.job_id; | ||
|
||
SELECT billing_project INTO cur_billing_project FROM batches WHERE id = NEW.batch_id; | ||
|
||
SET msec_diff_rollup = (GREATEST(COALESCE(NEW.rollup_time - NEW.start_time, 0), 0) - | ||
GREATEST(COALESCE(OLD.rollup_time - OLD.start_time, 0), 0)); | ||
|
||
SET cur_billing_date = CAST(UTC_DATE() AS DATE); | ||
|
||
IF msec_diff_rollup != 0 THEN | ||
INSERT INTO aggregated_billing_project_user_resources_v3 (billing_project, user, resource_id, token, `usage`) | ||
SELECT batches.billing_project, batches.`user`, | ||
attempt_resources.deduped_resource_id, | ||
rand_token, | ||
msec_diff_rollup * quantity | ||
FROM attempt_resources | ||
JOIN batches ON batches.id = attempt_resources.batch_id | ||
WHERE attempt_resources.batch_id = NEW.batch_id AND attempt_resources.job_id = NEW.job_id AND attempt_id = NEW.attempt_id | ||
ON DUPLICATE KEY UPDATE `usage` = aggregated_billing_project_user_resources_v3.`usage` + msec_diff_rollup * quantity; | ||
|
||
INSERT INTO aggregated_job_group_resources_v3 (batch_id, resource_id, token, `usage`) | ||
SELECT attempt_resources.batch_id, | ||
attempt_resources.deduped_resource_id, | ||
rand_token, | ||
msec_diff_rollup * quantity | ||
FROM attempt_resources | ||
WHERE attempt_resources.batch_id = NEW.batch_id AND attempt_resources.job_id = NEW.job_id AND attempt_id = NEW.attempt_id | ||
ON DUPLICATE KEY UPDATE `usage` = aggregated_job_group_resources_v3.`usage` + msec_diff_rollup * quantity; | ||
|
||
INSERT INTO aggregated_job_resources_v3 (batch_id, job_id, resource_id, `usage`) | ||
SELECT attempt_resources.batch_id, attempt_resources.job_id, | ||
attempt_resources.deduped_resource_id, | ||
msec_diff_rollup * quantity | ||
FROM attempt_resources | ||
WHERE attempt_resources.batch_id = NEW.batch_id AND attempt_resources.job_id = NEW.job_id AND attempt_id = NEW.attempt_id | ||
ON DUPLICATE KEY UPDATE `usage` = aggregated_job_resources_v3.`usage` + msec_diff_rollup * quantity; | ||
|
||
INSERT INTO aggregated_billing_project_user_resources_by_date_v3 (billing_date, billing_project, user, resource_id, token, `usage`) | ||
SELECT cur_billing_date, | ||
batches.billing_project, | ||
batches.`user`, | ||
attempt_resources.deduped_resource_id, | ||
rand_token, | ||
msec_diff_rollup * quantity | ||
FROM attempt_resources | ||
JOIN batches ON batches.id = attempt_resources.batch_id | ||
WHERE attempt_resources.batch_id = NEW.batch_id AND attempt_resources.job_id = NEW.job_id AND attempt_id = NEW.attempt_id | ||
ON DUPLICATE KEY UPDATE `usage` = aggregated_billing_project_user_resources_by_date_v3.`usage` + msec_diff_rollup * quantity; | ||
END IF; | ||
END $$ | ||
|
||
DROP TRIGGER IF EXISTS attempt_resources_after_insert $$ | ||
CREATE TRIGGER attempt_resources_after_insert AFTER INSERT ON attempt_resources | ||
FOR EACH ROW | ||
BEGIN | ||
DECLARE cur_start_time BIGINT; | ||
DECLARE cur_rollup_time BIGINT; | ||
DECLARE cur_billing_project VARCHAR(100); | ||
DECLARE cur_user VARCHAR(100); | ||
DECLARE msec_diff_rollup BIGINT; | ||
DECLARE cur_n_tokens INT; | ||
DECLARE rand_token INT; | ||
DECLARE cur_billing_date DATE; | ||
|
||
SELECT billing_project, user INTO cur_billing_project, cur_user | ||
FROM batches WHERE id = NEW.batch_id; | ||
|
||
SELECT n_tokens INTO cur_n_tokens FROM globals LOCK IN SHARE MODE; | ||
SET rand_token = FLOOR(RAND() * cur_n_tokens); | ||
|
||
SELECT start_time, rollup_time INTO cur_start_time, cur_rollup_time | ||
FROM attempts | ||
WHERE batch_id = NEW.batch_id AND job_id = NEW.job_id AND attempt_id = NEW.attempt_id | ||
LOCK IN SHARE MODE; | ||
|
||
SET msec_diff_rollup = GREATEST(COALESCE(cur_rollup_time - cur_start_time, 0), 0); | ||
|
||
SET cur_billing_date = CAST(UTC_DATE() AS DATE); | ||
|
||
IF msec_diff_rollup != 0 THEN | ||
INSERT INTO aggregated_billing_project_user_resources_v3 (billing_project, user, resource_id, token, `usage`) | ||
VALUES (cur_billing_project, cur_user, NEW.deduped_resource_id, rand_token, NEW.quantity * msec_diff_rollup) | ||
ON DUPLICATE KEY UPDATE | ||
`usage` = `usage` + NEW.quantity * msec_diff_rollup; | ||
|
||
INSERT INTO aggregated_job_group_resources_v3 (batch_id, resource_id, token, `usage`) | ||
VALUES (NEW.batch_id, NEW.deduped_resource_id, rand_token, NEW.quantity * msec_diff_rollup) | ||
ON DUPLICATE KEY UPDATE | ||
`usage` = `usage` + NEW.quantity * msec_diff_rollup; | ||
|
||
INSERT INTO aggregated_job_resources_v3 (batch_id, job_id, resource_id, `usage`) | ||
VALUES (NEW.batch_id, NEW.job_id, NEW.deduped_resource_id, NEW.quantity * msec_diff_rollup) | ||
ON DUPLICATE KEY UPDATE | ||
`usage` = `usage` + NEW.quantity * msec_diff_rollup; | ||
|
||
INSERT INTO aggregated_billing_project_user_resources_by_date_v3 (billing_date, billing_project, user, resource_id, token, `usage`) | ||
VALUES (cur_billing_date, cur_billing_project, cur_user, NEW.deduped_resource_id, rand_token, NEW.quantity * msec_diff_rollup) | ||
ON DUPLICATE KEY UPDATE | ||
`usage` = `usage` + NEW.quantity * msec_diff_rollup; | ||
END IF; | ||
END $$ | ||
|
||
DELIMITER ; |
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
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
And just checking here to make absolutely sure,
resource_id
anddeduped_resource_id
are the same in this table?There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
In the billing tables, there is no deduped_resource_id. The v2 table is essentially the "resource_id" in attempt_resources and the v3 table "resource_id" is equivalent to the "deduped_resource_id" in the attempt resources table.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Awesome, thanks!