Speed up sort-order-comparison tests in create_index_spgist.

This test script verifies that KNN searches of an SP-GiST index
produce the same sort order as a seqscan-and-sort.  The FULL JOINs
used for that are exceedingly slow, however.  Investigation shows
that the problem is that the initial join is on the rank() values,
and we have a lot of duplicates due to the data set containing 1000
duplicate points.  We're therefore going to produce 1000000 join
rows that have to be thrown away again by the join filter.

We can improve matters by using row_number() instead of rank(),
so that the initial join keys are unique.  The catch is that
that makes the results sensitive to the sorting of rows with
equal distances from the reference point.  That doesn't matter
for the actually-equal points, but as luck would have it, the
data set also contains two distinct points that have identical
distances to the origin.  So those two rows could legitimately
appear in either order, causing unwanted output from the check
queries.

However, it doesn't seem like it's the job of this test to
check whether the <-> operator correctly computes distances;
its charter is just to verify that SP-GiST emits the values
in distance order.  So we can dodge the indeterminacy problem
by having the check only compare row numbers and distances
not the actual point values.

This change reduces the run time of create_index_spgist by a good
three-quarters, on my machine, with ensuing beneficial effects on
the runtime of create_index (thanks to interactions with CREATE
INDEX CONCURRENTLY tests in the latter).  I see a net improvement
of more than 2X in the runtime of their parallel test group.

Discussion: https://postgr.es/m/735.1554935715@sss.pgh.pa.us
This commit is contained in:
Tom Lane 2019-04-11 17:01:35 -04:00
parent 385d396b80
commit 5874c70557
2 changed files with 48 additions and 60 deletions

View File

@ -81,13 +81,13 @@ SELECT count(*) FROM quad_point_tbl WHERE p ~= '(4585, 365)';
(1 row)
CREATE TEMP TABLE quad_point_tbl_ord_seq1 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl;
CREATE TEMP TABLE quad_point_tbl_ord_seq2 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl WHERE p <@ box '(200,200,1000,1000)';
CREATE TEMP TABLE quad_point_tbl_ord_seq3 AS
SELECT rank() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
SELECT row_number() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
FROM quad_point_tbl WHERE p IS NOT NULL;
SELECT count(*) FROM radix_text_tbl WHERE t = 'P0123456789abcdef';
count
@ -327,7 +327,7 @@ SELECT count(*) FROM quad_point_tbl WHERE p ~= '(4585, 365)';
(1 row)
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl;
QUERY PLAN
-----------------------------------------------------------
@ -337,18 +337,17 @@ FROM quad_point_tbl;
(3 rows)
CREATE TEMP TABLE quad_point_tbl_ord_idx1 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl;
SELECT * FROM quad_point_tbl_ord_seq1 seq FULL JOIN quad_point_tbl_ord_idx1 idx
ON seq.n = idx.n
AND (seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
WHERE seq.dist IS DISTINCT FROM idx.dist;
n | dist | p | n | dist | p
---+------+---+---+------+---
(0 rows)
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl WHERE p <@ box '(200,200,1000,1000)';
QUERY PLAN
-----------------------------------------------------------
@ -359,18 +358,17 @@ FROM quad_point_tbl WHERE p <@ box '(200,200,1000,1000)';
(4 rows)
CREATE TEMP TABLE quad_point_tbl_ord_idx2 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl WHERE p <@ box '(200,200,1000,1000)';
SELECT * FROM quad_point_tbl_ord_seq2 seq FULL JOIN quad_point_tbl_ord_idx2 idx
ON seq.n = idx.n
AND (seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
WHERE seq.dist IS DISTINCT FROM idx.dist;
n | dist | p | n | dist | p
---+------+---+---+------+---
(0 rows)
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
SELECT row_number() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
FROM quad_point_tbl WHERE p IS NOT NULL;
QUERY PLAN
-----------------------------------------------------------
@ -381,12 +379,11 @@ FROM quad_point_tbl WHERE p IS NOT NULL;
(4 rows)
CREATE TEMP TABLE quad_point_tbl_ord_idx3 AS
SELECT rank() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
SELECT row_number() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
FROM quad_point_tbl WHERE p IS NOT NULL;
SELECT * FROM quad_point_tbl_ord_seq3 seq FULL JOIN quad_point_tbl_ord_idx3 idx
ON seq.n = idx.n
AND (seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
WHERE seq.dist IS DISTINCT FROM idx.dist;
n | dist | p | n | dist | p
---+------+---+---+------+---
(0 rows)
@ -497,7 +494,7 @@ SELECT count(*) FROM kd_point_tbl WHERE p ~= '(4585, 365)';
(1 row)
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM kd_point_tbl;
QUERY PLAN
-------------------------------------------------------
@ -507,18 +504,17 @@ FROM kd_point_tbl;
(3 rows)
CREATE TEMP TABLE kd_point_tbl_ord_idx1 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM kd_point_tbl;
SELECT * FROM quad_point_tbl_ord_seq1 seq FULL JOIN kd_point_tbl_ord_idx1 idx
ON seq.n = idx.n AND
(seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
ON seq.n = idx.n
WHERE seq.dist IS DISTINCT FROM idx.dist;
n | dist | p | n | dist | p
---+------+---+---+------+---
(0 rows)
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM kd_point_tbl WHERE p <@ box '(200,200,1000,1000)';
QUERY PLAN
---------------------------------------------------------
@ -529,18 +525,17 @@ FROM kd_point_tbl WHERE p <@ box '(200,200,1000,1000)';
(4 rows)
CREATE TEMP TABLE kd_point_tbl_ord_idx2 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM kd_point_tbl WHERE p <@ box '(200,200,1000,1000)';
SELECT * FROM quad_point_tbl_ord_seq2 seq FULL JOIN kd_point_tbl_ord_idx2 idx
ON seq.n = idx.n AND
(seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
ON seq.n = idx.n
WHERE seq.dist IS DISTINCT FROM idx.dist;
n | dist | p | n | dist | p
---+------+---+---+------+---
(0 rows)
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
SELECT row_number() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
FROM kd_point_tbl WHERE p IS NOT NULL;
QUERY PLAN
-------------------------------------------------------
@ -551,12 +546,11 @@ FROM kd_point_tbl WHERE p IS NOT NULL;
(4 rows)
CREATE TEMP TABLE kd_point_tbl_ord_idx3 AS
SELECT rank() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
SELECT row_number() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
FROM kd_point_tbl WHERE p IS NOT NULL;
SELECT * FROM quad_point_tbl_ord_seq3 seq FULL JOIN kd_point_tbl_ord_idx3 idx
ON seq.n = idx.n AND
(seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
ON seq.n = idx.n
WHERE seq.dist IS DISTINCT FROM idx.dist;
n | dist | p | n | dist | p
---+------+---+---+------+---
(0 rows)

View File

@ -53,15 +53,15 @@ SELECT count(*) FROM quad_point_tbl WHERE p >^ '(5000, 4000)';
SELECT count(*) FROM quad_point_tbl WHERE p ~= '(4585, 365)';
CREATE TEMP TABLE quad_point_tbl_ord_seq1 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl;
CREATE TEMP TABLE quad_point_tbl_ord_seq2 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl WHERE p <@ box '(200,200,1000,1000)';
CREATE TEMP TABLE quad_point_tbl_ord_seq3 AS
SELECT rank() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
SELECT row_number() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
FROM quad_point_tbl WHERE p IS NOT NULL;
SELECT count(*) FROM radix_text_tbl WHERE t = 'P0123456789abcdef';
@ -138,37 +138,34 @@ SELECT count(*) FROM quad_point_tbl WHERE p ~= '(4585, 365)';
SELECT count(*) FROM quad_point_tbl WHERE p ~= '(4585, 365)';
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl;
CREATE TEMP TABLE quad_point_tbl_ord_idx1 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl;
SELECT * FROM quad_point_tbl_ord_seq1 seq FULL JOIN quad_point_tbl_ord_idx1 idx
ON seq.n = idx.n
AND (seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
WHERE seq.dist IS DISTINCT FROM idx.dist;
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl WHERE p <@ box '(200,200,1000,1000)';
CREATE TEMP TABLE quad_point_tbl_ord_idx2 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM quad_point_tbl WHERE p <@ box '(200,200,1000,1000)';
SELECT * FROM quad_point_tbl_ord_seq2 seq FULL JOIN quad_point_tbl_ord_idx2 idx
ON seq.n = idx.n
AND (seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
WHERE seq.dist IS DISTINCT FROM idx.dist;
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
SELECT row_number() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
FROM quad_point_tbl WHERE p IS NOT NULL;
CREATE TEMP TABLE quad_point_tbl_ord_idx3 AS
SELECT rank() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
SELECT row_number() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
FROM quad_point_tbl WHERE p IS NOT NULL;
SELECT * FROM quad_point_tbl_ord_seq3 seq FULL JOIN quad_point_tbl_ord_idx3 idx
ON seq.n = idx.n
AND (seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
WHERE seq.dist IS DISTINCT FROM idx.dist;
EXPLAIN (COSTS OFF)
SELECT count(*) FROM kd_point_tbl WHERE p <@ box '(200,200,1000,1000)';
@ -199,37 +196,34 @@ SELECT count(*) FROM kd_point_tbl WHERE p ~= '(4585, 365)';
SELECT count(*) FROM kd_point_tbl WHERE p ~= '(4585, 365)';
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM kd_point_tbl;
CREATE TEMP TABLE kd_point_tbl_ord_idx1 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM kd_point_tbl;
SELECT * FROM quad_point_tbl_ord_seq1 seq FULL JOIN kd_point_tbl_ord_idx1 idx
ON seq.n = idx.n AND
(seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
ON seq.n = idx.n
WHERE seq.dist IS DISTINCT FROM idx.dist;
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM kd_point_tbl WHERE p <@ box '(200,200,1000,1000)';
CREATE TEMP TABLE kd_point_tbl_ord_idx2 AS
SELECT rank() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
SELECT row_number() OVER (ORDER BY p <-> '0,0') n, p <-> '0,0' dist, p
FROM kd_point_tbl WHERE p <@ box '(200,200,1000,1000)';
SELECT * FROM quad_point_tbl_ord_seq2 seq FULL JOIN kd_point_tbl_ord_idx2 idx
ON seq.n = idx.n AND
(seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
ON seq.n = idx.n
WHERE seq.dist IS DISTINCT FROM idx.dist;
EXPLAIN (COSTS OFF)
SELECT rank() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
SELECT row_number() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
FROM kd_point_tbl WHERE p IS NOT NULL;
CREATE TEMP TABLE kd_point_tbl_ord_idx3 AS
SELECT rank() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
SELECT row_number() OVER (ORDER BY p <-> '333,400') n, p <-> '333,400' dist, p
FROM kd_point_tbl WHERE p IS NOT NULL;
SELECT * FROM quad_point_tbl_ord_seq3 seq FULL JOIN kd_point_tbl_ord_idx3 idx
ON seq.n = idx.n AND
(seq.dist = idx.dist AND seq.p ~= idx.p OR seq.p IS NULL AND idx.p IS NULL)
WHERE seq.n IS NULL OR idx.n IS NULL;
ON seq.n = idx.n
WHERE seq.dist IS DISTINCT FROM idx.dist;
EXPLAIN (COSTS OFF)
SELECT count(*) FROM radix_text_tbl WHERE t = 'P0123456789abcdef';