Postgresql 10 and EG 3.9.0
The query to grab holds on the hold shelf was taking 35-50 seconds on
a test system to return 466 records. Explain analyze showed that the
left join on asset.call_number was causing a sequential scan and reading
all asset.call_number rows.
Letting PG know that the two conditions of the join are mutually exclusive
seems to let PG know that an index scan is faster.
Signed-off-by: Josh Stompro <stomproj@larl.org>
Signed-off-by: Jason Stephenson <jstephenson@cwmars.org>
SELECT *, (ROW_NUMBER() OVER (ORDER BY name) + 1000000) AS fallback_position
FROM asset.copy_location
) acpl_ordered ON (acpl_ordered.id = cp.location)
- LEFT JOIN asset.call_number cn ON (cn.id = cp.call_number OR (h.hold_type = 'V' AND cn.id = h.target))
+ LEFT JOIN asset.call_number cn ON ((cn.id = cp.call_number AND h.hold_type != 'V' ) OR (h.hold_type = 'V' AND cn.id = h.target))
LEFT JOIN asset.call_number_prefix acnp ON (cn.prefix = acnp.id)
LEFT JOIN asset.call_number_suffix acns ON (cn.suffix = acns.id)
LEFT JOIN LATERAL (SELECT * FROM action.hold_transit_copy WHERE h.id = hold ORDER BY id DESC LIMIT 1) tr ON TRUE