So just for interests sake, to kick things up a notch (and out of sheer morbid curiosity), I loaded a higher-resolution dataset (Elevation data for the state of Alaska, 2 arc second resolution, as opposed to 100 meter resolution before). Same structure/indexes and everything, just higher resolution. So the new database has 1,642,700,002 rows, and is somewhere around 300GB in size (including index). Due to the larger data size, I moved the database to a different table space which resides on a mirrored 2TB spinning platter disk (i.e. slower both because of the RAID and lack of SSD). Friday evening I ran the following query: EXPLAIN ANALYZE WITH segments AS ( SELECT ST_MakeLine( lag((pt).geom , 1, NULL) OVER (ORDER BY (pt).path) ,(pt).geom)::GEOGRAPHY AS short_line FROM ST_DumpPoints( ST_Segmentize( ST_GeographyFromText('SRID=4326;LINESTRING(-150.008056 61.179167,-156.77 71.285833)'), 5000 )::geometry ) as pt ) SELECT elevation FROM data ,segments WHERE segments.short_line IS NOT NULL AND ST_DWithin(location, segments.short_line, 100) = TRUE ORDER BY elevation DESC limit 1; Which is the same query that took around 300 ms on the smaller dataset. The result was this (https://explain.depesz.com/s/mKFN): QUERY PLAN ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ Limit (cost=354643835.82..354643835.83 rows=1 width=9) (actual time=225998.319..225998.320 rows=1 loops=1) CTE segments -> WindowAgg (cost=60.08..82.58 rows=1000 width=64) (actual time=0.488..4.032 rows=234 loops=1) -> Sort (cost=60.08..62.58 rows=1000 width=64) (actual time=0.460..0.875 rows=234 loops=1) Sort Key: pt.path Sort Method: quicksort Memory: 57kB -> Function Scan on st_dumppoints pt (cost=0.25..10.25 rows=1000 width=64) (actual time=0.354..0.387 rows=234 loops=1) -> Sort (cost=354643753.25..354645115.32 rows=544829 width=9) (actual time=225998.319..225998.319 rows=1 loops=1) Sort Key: data.elevation DESC Sort Method: top-N heapsort Memory: 25kB -> Nested Loop (cost=0.68..354641029.10 rows=544829 width=9) (actual time=349.784..225883.557 rows=159654 loops=1) -> CTE Scan on segments (cost=0.00..20.00 rows=995 width=32) (actual time=0.500..4.823 rows=233 loops=1) Filter: (short_line IS NOT NULL) Rows Removed by Filter: 1 -> Index Scan using location_gist_idx on data (cost=0.68..356423.07 rows=5 width=41) (actual time=71.416..969.196 rows=685 loops=233) Index Cond: (location && _st_expand(segments.short_line, '100'::double precision)) Filter: ((segments.short_line && _st_expand(location, '100'::double precision)) AND _st_dwithin(location, segments.short_line, '100'::double precision, true)) Rows Removed by Filter: 8011 Planning time: 4.554 ms Execution time: 225998.839 ms (20 rows) So a little less than four minutes. Not bad (given the size of the database), or so I thought. This morning (so a couple of days later) I ran the query again without the explain analyze to check the results, and noticed that it didn't take anywhere near four minutes to execute. So I ran the explain analyze again, and got this: QUERY PLAN ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ Limit (cost=354643835.82..354643835.83 rows=1 width=9) (actual time=9636.165..9636.166 rows=1 loops=1) CTE segments -> WindowAgg (cost=60.08..82.58 rows=1000 width=64) (actual time=0.345..1.137 rows=234 loops=1) -> Sort (cost=60.08..62.58 rows=1000 width=64) (actual time=0.335..0.428 rows=234 loops=1) Sort Key: pt.path Sort Method: quicksort Memory: 57kB -> Function Scan on st_dumppoints pt (cost=0.25..10.25 rows=1000 width=64) (actual time=0.198..0.230 rows=234 loops=1) -> Sort (cost=354643753.25..354645115.32 rows=544829 width=9) (actual time=9636.165..9636.165 rows=1 loops=1) Sort Key: data.elevation DESC Sort Method: top-N heapsort Memory: 25kB -> Nested Loop (cost=0.68..354641029.10 rows=544829 width=9) (actual time=1.190..9602.606 rows=159654 loops=1) -> CTE Scan on segments (cost=0.00..20.00 rows=995 width=32) (actual time=0.361..1.318 rows=233 loops=1) Filter: (short_line IS NOT NULL) Rows Removed by Filter: 1 -> Index Scan using location_gist_idx on data (cost=0.68..356423.07 rows=5 width=41) (actual time=0.372..41.126 rows=685 loops=233) Index Cond: (location && _st_expand(segments.short_line, '100'::double precision)) Filter: ((segments.short_line && _st_expand(location, '100'::double precision)) AND _st_dwithin(location, segments.short_line, '100'::double precision, true)) Rows Removed by Filter: 8011 Planning time: 0.941 ms Execution time: 9636.285 ms (20 rows) So from four minutes on the first run to around 9 1/2 seconds on the second. Presumably this difference is due to caching? I would have expected any caches to have expired by the time I made the second run, but the data *is* static, so I guess not. Otherwise, I don't know how to explain the improvement on the second run - the query plans appear identical (at least to me). *IS* there something else (for example, auto vacuum running over the weekend) that could explain the performance difference? Assuming this performance difference *is* due to caching, that brings up a couple of questions for me: 1) Is there any way to "force" PostgreSQL to cache the data? Keep in mind that the database is close to a couple of hundred Gigs of data, so there is no way it can all fit in RAM. 2) In lieu of forcing a cache (which is probably not going to work well, even if possible), what could I do to help ensure that performance is closer to the 9 second mark than the 4 minute mark in general? For example, would it be likely to make a significant difference if I was to add a couple of larger SSD's to hold this data and put them in a stripe RAID (rather than the mirrored 7200 RPM platter drives it is on now)? Since the data is static, loosing the data due to drive failure is of little concern to me. Or would adding more RAM (and tweaking PostgreSQL settings) to be able to increase the cache size help more, even though there would still not be enough to cache everything? In the end, the low resolution data is probably good enough, and I may be able to come up with some sort of method to use them both - i.e. return a result quickly from the low resolution dataset, while simultaneously firing off the same request to the high resolution dataset, and returning that result when ready, or only using the high-resolution data set when explicitly requested. So having to wait four minutes on occasion for a result from the high-resolution set may not be an issue. That said, it would be nice to know all the options I can present to my boss :-) ----------------------------------------------- Israel Brewster Systems Analyst II Ravn Alaska 5245 Airport Industrial Rd Fairbanks, AK 99709 (907) 450-7293 ----------------------------------------------- |
BEGIN:VCARD VERSION:3.0 N:Brewster;Israel;;; FN:Israel Brewster ORG:Frontier Flying Service;MIS TITLE:PC Support Tech II EMAIL;type=INTERNET;type=WORK;type=pref:israel@xxxxxxxxxxxxxxxxxx TEL;type=WORK;type=pref:907-450-7293 item1.ADR;type=WORK;type=pref:;;5245 Airport Industrial Wy;Fairbanks;AK;99701; item1.X-ABADR:us CATEGORIES:General X-ABUID:36305438-95EA-4410-91AB-45D16CABCDDC\:ABPerson END:VCARD
|