From: Bill Erickson Date: Thu, 15 Mar 2018 15:16:25 +0000 (-0400) Subject: JBAS-1997 Prevent sequential scans in hold queue pos func X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=213ed9b3c964e9d1d5e8bef0b0ad87356c9e962c;p=working%2FEvergreen.git JBAS-1997 Prevent sequential scans in hold queue pos func Brute-force the PG planner to make it use index scans instead of sequential scans in the hold queue position stored proc. This resolves a problem where the planner starts using seq scans over time as the stats morph in the presence of lots of active, large-queue holds. Avoidin the seq scan shows consistently better performance. Signed-off-by: Bill Erickson --- diff --git a/KCLS/sql/schema/deploy/hold-queue-pos-func.sql b/KCLS/sql/schema/deploy/hold-queue-pos-func.sql index d63e29b35a..fec832877e 100644 --- a/KCLS/sql/schema/deploy/hold-queue-pos-func.sql +++ b/KCLS/sql/schema/deploy/hold-queue-pos-func.sql @@ -18,6 +18,7 @@ DECLARE related_id INTEGER; queue_pos INTEGER DEFAULT 1; BEGIN + SET enable_seqscan = false; FOR related_id IN SELECT id FROM ( SELECT ahr.id, ahr.cut_in_line, ahr.request_time FROM action.hold_request ahr @@ -29,10 +30,12 @@ BEGIN ORDER BY COALESCE (ahr.cut_in_line, FALSE) DESC, ahr.request_time ) related_holds LOOP IF related_id = hold_id THEN + RESET enable_seqscan; RETURN queue_pos; END IF; queue_pos = queue_pos + 1; END LOOP; + RESET enable_seqscan; RETURN -1; -- No such hold END; $FUNK$ LANGUAGE PLPGSQL;