Ahhh, I see you've done this sort of thing before (http://blog.cleverelephant.ca/2015/02/breaking-linestring-into-segments.html) :-) So following that advice I came up with the following query: WITH dump AS (SELECT ST_DumpPoints( ST_Segmentize( ST_GeographyFromText('SRID=4326;LINESTRING(-150.008056 61.179167,-156.77 71.285833)'), 600 )::geometry ) as pt ), pts AS ( SELECT (pt).geom, (pt).path[1] as vert FROM dump ) SELECT elevation FROM data INNER JOIN (SELECT ST_MakeLine(ARRAY[a.geom, b.geom]) as short_line FROM pts a INNER JOIN pts b ON a.vert=b.vert-1 AND b.vert>1) segments ON ST_DWithin(location, segments.short_line, 600) ORDER BY elevation DESC limit 1; Which yields the following EXPLAIN ANALYZE (https://explain.depesz.com/s/RsTD): QUERY PLAN -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- Limit (cost=11611706.90..11611706.91 rows=1 width=4) (actual time=1171.814..1171.814 rows=1 loops=1) CTE dump -> Result (cost=0.00..5.25 rows=1000 width=32) (actual time=0.024..1.989 rows=1939 loops=1) CTE pts -> CTE Scan on dump (cost=0.00..20.00 rows=1000 width=36) (actual time=0.032..4.071 rows=1939 loops=1) -> Sort (cost=11611681.65..11611768.65 rows=34800 width=4) (actual time=1171.813..1171.813 rows=1 loops=1) Sort Key: data.elevation DESC Sort Method: top-N heapsort Memory: 25kB -> Nested Loop (cost=0.55..11611507.65 rows=34800 width=4) (actual time=0.590..1167.615 rows=28408 loops=1) -> Nested Loop (cost=0.00..8357.50 rows=1665 width=64) (actual time=0.046..663.475 rows=1938 loops=1) Join Filter: (a.vert = (b.vert - 1)) Rows Removed by Join Filter: 3755844 -> CTE Scan on pts b (cost=0.00..22.50 rows=333 width=36) (actual time=0.042..0.433 rows=1938 loops=1) Filter: (vert > 1) Rows Removed by Filter: 1 -> CTE Scan on pts a (cost=0.00..20.00 rows=1000 width=36) (actual time=0.000..0.149 rows=1939 loops=1938) -> Index Scan using location_gix on data (cost=0.55..6968.85 rows=1 width=36) (actual time=0.085..0.256 rows=15 loops=1938) Index Cond: (location && _st_expand((st_makeline(ARRAY[a.geom, b.geom]))::geography, '600'::double precision)) Filter: (((st_makeline(ARRAY[a.geom, b.geom]))::geography && _st_expand(location, '600'::double precision)) AND _st_dwithin(location, (st_makeline(ARRAY[a.geom, b.geom]))::geography, '600'::double precision, true)) Rows Removed by Filter: 7 Planning time: 4.318 ms Execution time: 1171.994 ms (22 rows) So not bad. Went from 20+ seconds to a little over 1 second. Still noticeable for a end user, but defiantly usable - and like mentioned, that's a worst-case scenario query. Thanks! Of course, if you have any suggestions for further improvement, I'm all ears :-) ----------------------------------------------- Israel Brewster Systems Analyst II Ravn Alaska 5245 Airport Industrial Rd Fairbanks, AK 99709 (907) 450-7293 -----------------------------------------------
|