Skip to content
Open
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
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
Comment on lines +28 to +30
Copy link

Copilot AI Dec 12, 2025

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.

Suggested change
, 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
, sum(
case
when datediff_big(millisecond, dj.startedTime, @currentDate) > 0
then (case when dj.finishedTime is null then @timeout
else cast(datediff_big(millisecond,dj.startedTime, dj.finishedtime) as float)
end ) / cast(datediff_big(millisecond,dj.startedTime,@currentDate) as float)
else 0
end
) as usageWeight

Copilot uses AI. Check for mistakes.
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
Copy link

Copilot AI Dec 12, 2025

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Missing semicolon after the INSERT INTO statement. Adding a semicolon here would improve consistency and follow T-SQL best practices for statement termination.

Suggested change
where ranking <= @maxNum
where ranking <= @maxNum;

Copilot uses AI. Check for mistakes.
;

return
end