Skip to content

Commit

Permalink
jobs: avoid CTEs in crdb_internal.system_jobs query
Browse files Browse the repository at this point in the history
The CTE in the query used for crdb_internal.system_jobs can prevent a
number of useful query optimizations.

Informs cockroachdb#122687

Release note (performance improvement): Further improves the
performance of job-system related queries.
  • Loading branch information
stevendanna committed May 29, 2024
1 parent 604bb00 commit 947580d
Show file tree
Hide file tree
Showing 2 changed files with 17 additions and 26 deletions.
1 change: 1 addition & 0 deletions pkg/bench/rttanalysis/testdata/benchmark_expectations
Original file line number Diff line number Diff line change
Expand Up @@ -66,6 +66,7 @@ exp,benchmark
3,Jobs/jobs_page_default
3,Jobs/jobs_page_latest_50
3,Jobs/jobs_page_type_filtered
1,Jobs/jobs_page_type_filtered_no_matches
3,Jobs/jobs_page_type_filtered_no_matches
8,Jobs/pause_job
6,Jobs/resume_job
Expand Down
42 changes: 16 additions & 26 deletions pkg/sql/crdb_internal.go
Original file line number Diff line number Diff line change
Expand Up @@ -964,32 +964,22 @@ const (
// so we perform a LEFT JOIN to get a NULL value when no progress row is
// found.
systemJobsAndJobInfoBaseQuery = `
WITH
latestpayload AS (SELECT job_id, value FROM system.job_info AS payload WHERE info_key = 'legacy_payload' ORDER BY written DESC),
latestprogress AS (SELECT job_id, value FROM system.job_info AS progress WHERE info_key = 'legacy_progress' ORDER BY written DESC)
SELECT
DISTINCT(id), status, created, payload.value AS payload, progress.value AS progress,
created_by_type, created_by_id, claim_session_id, claim_instance_id, num_runs, last_run, job_type
FROM system.jobs AS j
INNER JOIN latestpayload AS payload ON j.id = payload.job_id
LEFT JOIN latestprogress AS progress ON j.id = progress.job_id
`

// systemJobsAndJobInfoBaseQueryWithIDPredicate is the same as
// systemJobsAndJobInfoBaseQuery but with a predicate on `job_id` in the CTE
// queries.
systemJobsAndJobInfoBaseQueryWithIDPredicate = `
WITH
latestpayload AS (SELECT job_id, value FROM system.job_info AS payload WHERE info_key = 'legacy_payload' AND job_id = $1 ORDER BY written DESC LIMIT 1),
latestprogress AS (SELECT job_id, value FROM system.job_info AS progress WHERE info_key = 'legacy_progress' AND job_id = $1 ORDER BY written DESC LIMIT 1)
SELECT
id, status, created, payload.value AS payload, progress.value AS progress,
created_by_type, created_by_id, claim_session_id, claim_instance_id, num_runs, last_run, job_type
FROM system.jobs AS j
INNER JOIN latestpayload AS payload ON j.id = payload.job_id
LEFT JOIN latestprogress AS progress ON j.id = progress.job_id
SELECT
DISTINCT(id), status, created, payload.value AS payload, progress.value AS progress,
created_by_type, created_by_id, claim_session_id, claim_instance_id, num_runs, last_run, job_type
FROM
system.jobs AS j
LEFT JOIN (
SELECT job_id, value FROM system.job_info
WHERE info_key = 'legacy_progress'
ORDER BY written DESC
) AS progress ON j.id = progress.job_id
INNER JOIN (
SELECT job_id, value FROM system.job_info
WHERE info_key = 'legacy_payload'
ORDER BY written DESC
) AS payload ON j.id = payload.job_id
`

systemJobsIDPredicate = ` WHERE id = $1`
systemJobsTypePredicate = ` WHERE job_type = $1`
systemJobsStatusPredicate = ` WHERE status = $1`
Expand All @@ -1009,7 +999,7 @@ func getInternalSystemJobsQuery(predicate systemJobsPredicate) string {
case noPredicate:
return systemJobsAndJobInfoBaseQuery
case jobID:
return systemJobsAndJobInfoBaseQueryWithIDPredicate + systemJobsIDPredicate
return systemJobsAndJobInfoBaseQuery + systemJobsIDPredicate
case jobType:
return systemJobsAndJobInfoBaseQuery + systemJobsTypePredicate
case jobStatus:
Expand Down

0 comments on commit 947580d

Please sign in to comment.