-
Notifications
You must be signed in to change notification settings - Fork 3
improved performance of racm.nextJobsRestricted UDF. using table vari… #83
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
Open
glemson
wants to merge
5
commits into
main
Choose a base branch
from
fix-nextJobsRestricted-UDF
base: main
Could not load branches
Branch not found: {{ refName }}
Loading
Could not load tags
Nothing to show
Loading
Are you sure you want to change the base?
Some commits from the old base branch may be removed from the timeline,
and old review comments may become outdated.
Open
Changes from all commits
Commits
Show all changes
5 commits
Select commit
Hold shift + click to select a range
460bc15
improved performance of racm.nextJobsRestricted UDF. using table vari…
glemson 879d96c
formatting fixes
glemson 7abf525
formatting updates suggested by copilot
glemson 854428b
formatting updates suggested by copolit
glemson ff1f7d9
further formatting updates
glemson 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
72 changes: 72 additions & 0 deletions
72
components/java/racm/src/main/resources/db/migration/V34__Alter_nextJobsRestricted_UDF.sql
This file contains hidden or 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,72 @@ | ||||||
| CREATE OR ALTER function [racm].[nextJobsRestricted](@compmUUID varchar(64), @timeout real, | ||||||
| @interval real, @maxNum integer, @maxPerUser integer) | ||||||
| returns @rt table( | ||||||
| jobId bigint, submitterId bigint, | ||||||
| computeDomainId bigint, submitTime datetime, | ||||||
| usageWeight float, numQueued integer, numStarted integer, ranking integer) | ||||||
| as | ||||||
| begin | ||||||
|
|
||||||
| declare @computeDomainId bigint, @currentDate datetime = getDate(); | ||||||
|
|
||||||
| select @computeDomainId = computeDomainId | ||||||
| from COMPM | ||||||
| where uuid=@compmUUID | ||||||
| ; | ||||||
|
|
||||||
| declare @prev table (submitterId bigint, numJobs integer, numQueued integer, | ||||||
| numStarted integer, totTime float, usageWeight float); | ||||||
|
|
||||||
| insert into @prev | ||||||
| select dj.submitterId | ||||||
| , count(*) as numJobs | ||||||
| , sum(case when dj.status between 2 and 4 then 1 else 0 end) as numQueued | ||||||
| , sum(case when dj.status = 8 then 1 else 0 end) as numStarted | ||||||
| , sum(case when dj.finishedTime is null then @timeout | ||||||
| else cast(datediff(second,dj.startedTime, dj.finishedtime) as float) | ||||||
| end ) as totTime | ||||||
| , sum((case when dj.finishedTime is null then @timeout | ||||||
| else cast(datediff_big(millisecond,dj.startedTime, dj.finishedtime) as float) | ||||||
| end )/datediff_big(millisecond,dj.startedTime,@currentDate)) as usageWeight | ||||||
| from compm c | ||||||
| join job dj | ||||||
| on dj.computeDomainId=c.computeDomainId | ||||||
| and dj.status > 1 -- 1 = PENDING | ||||||
| and dj.startedTime >= dateadd(second,-@interval,getDate()) | ||||||
| where c.uuid = @compmUUID | ||||||
| group by submitterid | ||||||
| ; | ||||||
|
|
||||||
| declare @pending table (id bigint, submitterId bigint, computeDomainId bigint, | ||||||
| submitTime datetime, rankSubmitted integer); | ||||||
|
|
||||||
| insert into @pending | ||||||
| select dj.id, dj.submitterId, dj.computeDomainId, submitTime, | ||||||
| rank() over (partition by submitterId order by submitTime) as rankSubmitted | ||||||
| from compm c | ||||||
| join job dj | ||||||
| on dj.computeDomainId=c.computeDomainId | ||||||
| where c.uuid = @compmUUID | ||||||
| and dj.status=1 -- 1 = PENDING | ||||||
| ; | ||||||
|
|
||||||
| with final as ( | ||||||
| select j.id as jobId,j.submitterId, j.computeDomainId, j.submitTime | ||||||
| , isnull(p.usageWeight,0) as usageWeight | ||||||
| , isnull(p.numQueued,0) as numQueued | ||||||
| , isnull(p.numStarted,0) as numStarted | ||||||
| , rank() over (order by rankSubmitted,usageWeight,submitTime) as ranking | ||||||
| from @pending j | ||||||
| left outer join @prev p | ||||||
| on p.submitterId = j.submitterid | ||||||
| where j.rankSubmitted <=@maxNum | ||||||
| and j.rankSubmitted+isnull(p.numQueued,0)+isnull(p.numStarted,0)<=@maxPerUser | ||||||
| ) | ||||||
| insert into @rt | ||||||
| select * -- RETURNS: jobId,submitterId, computeDomainId, submitTime , usageWeight, numQueued, numStarted, ranking | ||||||
| from final | ||||||
| where ranking <= @maxNum | ||||||
|
||||||
| where ranking <= @maxNum | |
| where ranking <= @maxNum; |
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.
The usageWeight calculation has a potential division by zero issue. When dj.startedTime equals @CurrentDate (which could happen if a job just started), the datediff_big will return 0, causing a divide-by-zero error. Additionally, if startedTime is greater than @CurrentDate (future date), the result would be negative. Consider adding validation to ensure startedTime is less than @CurrentDate and the difference is greater than zero before performing the division.