On Wed, 26 Aug 2015, Henrik Thostrup Jensen wrote:
Can you try 9.5 to see if they help?
I'll try installing it and report back.
I upgraded to 9.5 (easier than expected) and ran vacuum analyze.
The query planner now chooses index scan for outer and inner join. This
seems to cut off roughly a second or so (31s -> 30s, and 17s->16s for when
using distint on initial route set).
Query:
EXPLAIN (ANALYZE, BUFFERS)
SELECT rv.route, rv.asn, rv.source FROM
(SELECT DISTINCT route FROM routes_view WHERE asn = %s) r
INNER JOIN routes_view rv ON (r.route && rv.route)
ORDER BY rv.route;
Explain analyze: http://explain.depesz.com/s/L7kZ
9.5 also seems to fix the case with using CTE/WITH was actually slower.
The fastest I can currently do is this, which finds the minimal set of
covering routes before joining:
SET enable_bitmapscan = false;
EXPLAIN ANALYZE
WITH
distinct_routes AS (SELECT DISTINCT route FROM routes_view WHERE asn = %s),
minimal_routes AS (SELECT route FROM distinct_routes
EXCEPT
SELECT r1.route
FROM distinct_routes r1 INNER JOIN distinct_routes r2 ON (r1.route << r2.route))
SELECT rv.route, rv.asn, rv.source
FROM routes_view rv
JOIN minimal_routes ON (rv.route <<= minimal_routes.route);
Explain analyze: http://explain.depesz.com/s/Plx4
The query planner chooses bitmap Index Scan for this query, which adds
around .5 second the query time, so it isn't that bad of a decision.
Unfortunately it still takes 15 seconds for my test case (a big network,
but still a factor 10 from the biggest).
Are the coverage operatons just that expensive?
Best regards, Henrik
--
Sent via pgsql-performance mailing list (pgsql-performance@xxxxxxxxxxxxxx)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance