Fix behavior of ~> (cube, int) operator

~> (cube, int) operator was especially designed for knn-gist search.
However, it appears that knn-gist search can't work correctly with current
behavior of this operator when dataset contains cubes of variable
dimensionality. In this case, the same value of second operator argument
can point to different dimension depending on dimensionality of particular cube.
Such behavior is incompatible with gist indexing of cubes, and knn-gist doesn't
work correctly for it.

This patch changes behavior of ~> (cube, int) operator by introducing dimension
numbering where value of second argument unambiguously identifies number of
dimension. With new behavior, this operator can be correctly supported by
knn-gist. Relevant changes to cube operator class are also included.

Backpatch to v9.6 where operator was introduced.

Since behavior of ~> (cube, int) operator is changed, depending entities
must be refreshed after upgrade. Such as, expression indexes using this
operator must be reindexed, materialized views must be rebuilt, stored
procedures and client code must be revised to correctly use new behavior.
That should be mentioned in release notes.

Noticed by: Tomas Vondra
Author: Alexander Korotkov
Reviewed by: Tomas Vondra, Andrey Borodin
Discussion: https://www.postgresql.org/message-id/flat/a9657f6a-b497-36ff-e56-482a2c7e3292@2ndquadrant.com
This commit is contained in:
Teodor Sigaev 2018-01-11 14:41:14 +03:00
parent 3c1e9fd232
commit 563a053bdd
5 changed files with 511 additions and 285 deletions

View File

@ -1337,15 +1337,55 @@ g_cube_distance(PG_FUNCTION_ARGS)
if (strategy == CubeKNNDistanceCoord)
{
/*
* Handle ordering by ~> operator. See comments of cube_coord_llur()
* for details
*/
int coord = PG_GETARG_INT32(1);
bool isLeaf = GistPageIsLeaf(entry->page);
if (DIM(cube) == 0)
retval = 0.0;
else if (IS_POINT(cube))
retval = cube->x[(coord - 1) % DIM(cube)];
/* 0 is the only unsupported coordinate value */
if (coord <= 0)
ereport(ERROR,
(errcode(ERRCODE_ARRAY_ELEMENT_ERROR),
errmsg("cube index %d is out of bounds", coord)));
if (coord <= 2 * DIM(cube))
{
/* dimension index */
int index = (coord - 1) / 2;
/* whether this is upper bound (lower bound otherwise) */
bool upper = ((coord - 1) % 2 == 1);
if (IS_POINT(cube))
{
retval = cube->x[index];
}
else
{
if (isLeaf)
{
/* For leaf just return required upper/lower bound */
if (upper)
retval = Max(cube->x[index], cube->x[index + DIM(cube)]);
else
retval = Min(cube->x[index], cube->x[index + DIM(cube)]);
}
else
{
/*
* For non-leaf we should always return lower bound,
* because even upper bound of a child in the subtree can
* be as small as our lower bound.
*/
retval = Min(cube->x[index], cube->x[index + DIM(cube)]);
}
}
}
else
retval = Min(cube->x[(coord - 1) % DIM(cube)],
cube->x[(coord - 1) % DIM(cube) + DIM(cube)]);
{
retval = 0.0;
}
}
else
{
@ -1492,43 +1532,73 @@ cube_coord(PG_FUNCTION_ARGS)
}
/*
* This function works like cube_coord(),
* but rearranges coordinates of corners to get cube representation
* in the form of (lower left, upper right).
* For historical reasons that extension allows us to create cubes in form
* ((2,1),(1,2)) and instead of normalizing such cube to ((1,1),(2,2)) it
* stores cube in original way. But to get cubes ordered by one of dimensions
* directly from the index without extra sort step we need some
* representation-independent coordinate getter. This function implements it.
/*----
* This function works like cube_coord(), but rearranges coordinates in the
* way suitable to support coordinate ordering using KNN-GiST. For historical
* reasons this extension allows us to create cubes in form ((2,1),(1,2)) and
* instead of normalizing such cube to ((1,1),(2,2)) it stores cube in original
* way. But in order to get cubes ordered by one of dimensions from the index
* without explicit sort step we need this representation-independent coordinate
* getter. Moreover, indexed dataset may contain cubes of different dimensions
* number. Accordingly, this coordinate getter should be able to return
* lower/upper bound for particular dimension independently on number of cube
* dimensions.
*
* Long story short, this function uses following meaning of coordinates:
* # (2 * N - 1) -- lower bound of Nth dimension,
* # (2 * N) -- upper bound of Nth dimension.
*
* When given coordinate exceeds number of cube dimensions, then 0 returned
* (reproducing logic of GiST indexing of variable-length cubes).
*/
Datum
cube_coord_llur(PG_FUNCTION_ARGS)
{
NDBOX *cube = PG_GETARG_NDBOX_P(0);
int coord = PG_GETARG_INT32(1);
bool inverse = false;
float8 result;
if (coord <= 0 || coord > 2 * DIM(cube))
/* 0 is the only unsupported coordinate value */
if (coord <= 0)
ereport(ERROR,
(errcode(ERRCODE_ARRAY_ELEMENT_ERROR),
errmsg("cube index %d is out of bounds", coord)));
if (coord <= DIM(cube))
if (coord <= 2 * DIM(cube))
{
/* dimension index */
int index = (coord - 1) / 2;
/* whether this is upper bound (lower bound otherwise) */
bool upper = ((coord - 1) % 2 == 1);
if (IS_POINT(cube))
PG_RETURN_FLOAT8(cube->x[coord - 1]);
{
result = cube->x[index];
}
else
PG_RETURN_FLOAT8(Min(cube->x[coord - 1],
cube->x[coord - 1 + DIM(cube)]));
{
if (upper)
result = Max(cube->x[index], cube->x[index + DIM(cube)]);
else
result = Min(cube->x[index], cube->x[index + DIM(cube)]);
}
}
else
{
if (IS_POINT(cube))
PG_RETURN_FLOAT8(cube->x[(coord - 1) % DIM(cube)]);
else
PG_RETURN_FLOAT8(Max(cube->x[coord - 1],
cube->x[coord - 1 - DIM(cube)]));
/*
* Return zero if coordinate is out of bound. That reproduces logic of
* how cubes with low dimension number are expanded during GiST
* indexing.
*/
result = 0.0;
}
/* Inverse value if needed */
if (inverse)
result = -result;
PG_RETURN_FLOAT8(result);
}
/* Increase or decrease box size by a radius in at least n dimensions. */

View File

@ -1532,25 +1532,25 @@ SELECT cube(array[40,50,60], array[10,20,30])~>1;
SELECT cube(array[10,20,30], array[40,50,60])~>2;
?column?
----------
20
40
(1 row)
SELECT cube(array[40,50,60], array[10,20,30])~>2;
?column?
----------
20
40
(1 row)
SELECT cube(array[10,20,30], array[40,50,60])~>3;
?column?
----------
30
20
(1 row)
SELECT cube(array[40,50,60], array[10,20,30])~>3;
?column?
----------
30
20
(1 row)
SELECT cube(array[40,50,60], array[10,20,30])~>0;
@ -1558,7 +1558,7 @@ ERROR: cube index 0 is out of bounds
SELECT cube(array[40,50,60], array[10,20,30])~>4;
?column?
----------
40
50
(1 row)
SELECT cube(array[40,50,60], array[10,20,30])~>(-1);
@ -1611,25 +1611,28 @@ SELECT c FROM test_cube WHERE c <@ '(3000,1000),(0,0)' ORDER BY c;
(4 rows)
RESET enable_bitmapscan;
-- kNN with index
-- Test kNN
INSERT INTO test_cube VALUES ('(1,1)'), ('(100000)'), ('(0, 100000)'); -- Some corner cases
SET enable_seqscan = false;
-- Test different metrics
SELECT *, c <-> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <-> '(100, 100),(500, 500)'::cube LIMIT 5;
c | dist
-------------------------+------------------
(337, 455),(240, 359) | 0
(1, 1) | 140.007142674936
(759, 187),(662, 163) | 162
(948, 1201),(907, 1156) | 772.000647668122
(1444, 403),(1346, 344) | 846
(369, 1457),(278, 1409) | 909
(5 rows)
SELECT *, c <=> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <=> '(100, 100),(500, 500)'::cube LIMIT 5;
c | dist
-------------------------+------
(337, 455),(240, 359) | 0
(1, 1) | 99
(759, 187),(662, 163) | 162
(948, 1201),(907, 1156) | 656
(1444, 403),(1346, 344) | 846
(369, 1457),(278, 1409) | 909
(5 rows)
SELECT *, c <#> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <#> '(100, 100),(500, 500)'::cube LIMIT 5;
@ -1637,133 +1640,203 @@ SELECT *, c <#> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c
-------------------------+------
(337, 455),(240, 359) | 0
(759, 187),(662, 163) | 162
(1, 1) | 198
(1444, 403),(1346, 344) | 846
(369, 1457),(278, 1409) | 909
(948, 1201),(907, 1156) | 1063
(5 rows)
-- kNN-based sorting
SELECT * FROM test_cube ORDER BY c~>1 LIMIT 15; -- ascending by 1st coordinate of lower left corner
c
---------------------------
(54, 38679),(3, 38602)
(83, 10271),(15, 10265)
(122, 46832),(64, 46762)
(167, 17214),(92, 17184)
(161, 24465),(107, 24374)
(162, 26040),(120, 25963)
(154, 4019),(138, 3990)
(259, 1850),(175, 1820)
(207, 40886),(179, 40879)
(288, 49588),(204, 49571)
(270, 32616),(226, 32607)
(318, 31489),(235, 31404)
(337, 455),(240, 359)
(270, 29508),(264, 29440)
(369, 1457),(278, 1409)
-- Test sorting by coordinates
SELECT c~>1, c FROM test_cube ORDER BY c~>1 LIMIT 15; -- ascending by left bound
?column? | c
----------+---------------------------
0 | (0, 100000)
1 | (1, 1)
3 | (54, 38679),(3, 38602)
15 | (83, 10271),(15, 10265)
64 | (122, 46832),(64, 46762)
92 | (167, 17214),(92, 17184)
107 | (161, 24465),(107, 24374)
120 | (162, 26040),(120, 25963)
138 | (154, 4019),(138, 3990)
175 | (259, 1850),(175, 1820)
179 | (207, 40886),(179, 40879)
204 | (288, 49588),(204, 49571)
226 | (270, 32616),(226, 32607)
235 | (318, 31489),(235, 31404)
240 | (337, 455),(240, 359)
(15 rows)
SELECT * FROM test_cube ORDER BY c~>4 LIMIT 15; -- ascending by 2nd coordinate or upper right corner
c
---------------------------
(30333, 50),(30273, 6)
(43301, 75),(43227, 43)
(19650, 142),(19630, 51)
(2424, 160),(2424, 81)
(3449, 171),(3354, 108)
(18037, 155),(17941, 109)
(28511, 208),(28479, 114)
(19946, 217),(19941, 118)
(16906, 191),(16816, 139)
(759, 187),(662, 163)
(22684, 266),(22656, 181)
(24423, 255),(24360, 213)
(45989, 249),(45910, 222)
(11399, 377),(11360, 294)
(12162, 389),(12103, 309)
SELECT c~>2, c FROM test_cube ORDER BY c~>2 LIMIT 15; -- ascending by right bound
?column? | c
----------+---------------------------
0 | (0, 100000)
1 | (1, 1)
54 | (54, 38679),(3, 38602)
83 | (83, 10271),(15, 10265)
122 | (122, 46832),(64, 46762)
154 | (154, 4019),(138, 3990)
161 | (161, 24465),(107, 24374)
162 | (162, 26040),(120, 25963)
167 | (167, 17214),(92, 17184)
207 | (207, 40886),(179, 40879)
259 | (259, 1850),(175, 1820)
270 | (270, 29508),(264, 29440)
270 | (270, 32616),(226, 32607)
288 | (288, 49588),(204, 49571)
318 | (318, 31489),(235, 31404)
(15 rows)
SELECT * FROM test_cube ORDER BY c~>1 DESC LIMIT 15; -- descending by 1st coordinate of lower left corner
c
-------------------------------
(50027, 49230),(49951, 49214)
(49980, 35004),(49937, 34963)
(49985, 6436),(49927, 6338)
(49999, 27218),(49908, 27176)
(49954, 1340),(49905, 1294)
(49944, 25163),(49902, 25153)
(49981, 34876),(49898, 34786)
(49957, 43390),(49897, 43384)
(49853, 18504),(49848, 18503)
(49902, 41752),(49818, 41746)
(49907, 30225),(49810, 30158)
(49843, 5175),(49808, 5145)
(49887, 24274),(49805, 24184)
(49847, 7128),(49798, 7067)
(49820, 7990),(49771, 7967)
SELECT c~>3, c FROM test_cube ORDER BY c~>3 LIMIT 15; -- ascending by lower bound
?column? | c
----------+---------------------------
0 | (100000)
1 | (1, 1)
6 | (30333, 50),(30273, 6)
43 | (43301, 75),(43227, 43)
51 | (19650, 142),(19630, 51)
81 | (2424, 160),(2424, 81)
108 | (3449, 171),(3354, 108)
109 | (18037, 155),(17941, 109)
114 | (28511, 208),(28479, 114)
118 | (19946, 217),(19941, 118)
139 | (16906, 191),(16816, 139)
163 | (759, 187),(662, 163)
181 | (22684, 266),(22656, 181)
213 | (24423, 255),(24360, 213)
222 | (45989, 249),(45910, 222)
(15 rows)
SELECT * FROM test_cube ORDER BY c~>4 DESC LIMIT 15; -- descending by 2nd coordinate or upper right corner
c
-------------------------------
(36311, 50073),(36258, 49987)
(30746, 50040),(30727, 49992)
(2168, 50012),(2108, 49914)
(21551, 49983),(21492, 49885)
(17954, 49975),(17865, 49915)
(3531, 49962),(3463, 49934)
(19128, 49932),(19112, 49849)
(31287, 49923),(31236, 49913)
(43925, 49912),(43888, 49878)
(29261, 49910),(29247, 49818)
(14913, 49873),(14849, 49836)
(20007, 49858),(19921, 49778)
(38266, 49852),(38233, 49844)
(37595, 49849),(37581, 49834)
(46151, 49848),(46058, 49830)
SELECT c~>4, c FROM test_cube ORDER BY c~>4 LIMIT 15; -- ascending by upper bound
?column? | c
----------+---------------------------
0 | (100000)
1 | (1, 1)
50 | (30333, 50),(30273, 6)
75 | (43301, 75),(43227, 43)
142 | (19650, 142),(19630, 51)
155 | (18037, 155),(17941, 109)
160 | (2424, 160),(2424, 81)
171 | (3449, 171),(3354, 108)
187 | (759, 187),(662, 163)
191 | (16906, 191),(16816, 139)
208 | (28511, 208),(28479, 114)
217 | (19946, 217),(19941, 118)
249 | (45989, 249),(45910, 222)
255 | (24423, 255),(24360, 213)
266 | (22684, 266),(22656, 181)
(15 rows)
-- same thing for index with points
CREATE TABLE test_point(c cube);
INSERT INTO test_point(SELECT cube(array[c->1,c->2,c->3,c->4]) FROM test_cube);
CREATE INDEX ON test_point USING gist(c);
SELECT * FROM test_point ORDER BY c~>1, c~>2 LIMIT 15; -- ascending by 1st then by 2nd coordinate
c
--------------------------
(54, 38679, 3, 38602)
(83, 10271, 15, 10265)
(122, 46832, 64, 46762)
(154, 4019, 138, 3990)
(161, 24465, 107, 24374)
(162, 26040, 120, 25963)
(167, 17214, 92, 17184)
(207, 40886, 179, 40879)
(259, 1850, 175, 1820)
(270, 29508, 264, 29440)
(270, 32616, 226, 32607)
(288, 49588, 204, 49571)
(318, 31489, 235, 31404)
(326, 18837, 285, 18817)
(337, 455, 240, 359)
-- Same queries with sequential scan (should give the same results as above)
RESET enable_seqscan;
SET enable_indexscan = OFF;
SELECT *, c <-> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <-> '(100, 100),(500, 500)'::cube LIMIT 5;
c | dist
-------------------------+------------------
(337, 455),(240, 359) | 0
(1, 1) | 140.007142674936
(759, 187),(662, 163) | 162
(948, 1201),(907, 1156) | 772.000647668122
(1444, 403),(1346, 344) | 846
(5 rows)
SELECT *, c <=> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <=> '(100, 100),(500, 500)'::cube LIMIT 5;
c | dist
-------------------------+------
(337, 455),(240, 359) | 0
(1, 1) | 99
(759, 187),(662, 163) | 162
(948, 1201),(907, 1156) | 656
(1444, 403),(1346, 344) | 846
(5 rows)
SELECT *, c <#> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <#> '(100, 100),(500, 500)'::cube LIMIT 5;
c | dist
-------------------------+------
(337, 455),(240, 359) | 0
(759, 187),(662, 163) | 162
(1, 1) | 198
(1444, 403),(1346, 344) | 846
(369, 1457),(278, 1409) | 909
(5 rows)
SELECT c~>1, c FROM test_cube ORDER BY c~>1 LIMIT 15; -- ascending by left bound
?column? | c
----------+---------------------------
0 | (0, 100000)
1 | (1, 1)
3 | (54, 38679),(3, 38602)
15 | (83, 10271),(15, 10265)
64 | (122, 46832),(64, 46762)
92 | (167, 17214),(92, 17184)
107 | (161, 24465),(107, 24374)
120 | (162, 26040),(120, 25963)
138 | (154, 4019),(138, 3990)
175 | (259, 1850),(175, 1820)
179 | (207, 40886),(179, 40879)
204 | (288, 49588),(204, 49571)
226 | (270, 32616),(226, 32607)
235 | (318, 31489),(235, 31404)
240 | (337, 455),(240, 359)
(15 rows)
SELECT * FROM test_point ORDER BY c~>4 DESC LIMIT 15; -- descending by 1st coordinate
c
------------------------------
(30746, 50040, 30727, 49992)
(36311, 50073, 36258, 49987)
(3531, 49962, 3463, 49934)
(17954, 49975, 17865, 49915)
(2168, 50012, 2108, 49914)
(31287, 49923, 31236, 49913)
(21551, 49983, 21492, 49885)
(43925, 49912, 43888, 49878)
(19128, 49932, 19112, 49849)
(38266, 49852, 38233, 49844)
(14913, 49873, 14849, 49836)
(37595, 49849, 37581, 49834)
(46151, 49848, 46058, 49830)
(29261, 49910, 29247, 49818)
(19233, 49824, 19185, 49794)
SELECT c~>2, c FROM test_cube ORDER BY c~>2 LIMIT 15; -- ascending by right bound
?column? | c
----------+---------------------------
0 | (0, 100000)
1 | (1, 1)
54 | (54, 38679),(3, 38602)
83 | (83, 10271),(15, 10265)
122 | (122, 46832),(64, 46762)
154 | (154, 4019),(138, 3990)
161 | (161, 24465),(107, 24374)
162 | (162, 26040),(120, 25963)
167 | (167, 17214),(92, 17184)
207 | (207, 40886),(179, 40879)
259 | (259, 1850),(175, 1820)
270 | (270, 29508),(264, 29440)
270 | (270, 32616),(226, 32607)
288 | (288, 49588),(204, 49571)
318 | (318, 31489),(235, 31404)
(15 rows)
SELECT c~>3, c FROM test_cube ORDER BY c~>3 LIMIT 15; -- ascending by lower bound
?column? | c
----------+---------------------------
0 | (100000)
1 | (1, 1)
6 | (30333, 50),(30273, 6)
43 | (43301, 75),(43227, 43)
51 | (19650, 142),(19630, 51)
81 | (2424, 160),(2424, 81)
108 | (3449, 171),(3354, 108)
109 | (18037, 155),(17941, 109)
114 | (28511, 208),(28479, 114)
118 | (19946, 217),(19941, 118)
139 | (16906, 191),(16816, 139)
163 | (759, 187),(662, 163)
181 | (22684, 266),(22656, 181)
213 | (24423, 255),(24360, 213)
222 | (45989, 249),(45910, 222)
(15 rows)
SELECT c~>4, c FROM test_cube ORDER BY c~>4 LIMIT 15; -- ascending by upper bound
?column? | c
----------+---------------------------
0 | (100000)
1 | (1, 1)
50 | (30333, 50),(30273, 6)
75 | (43301, 75),(43227, 43)
142 | (19650, 142),(19630, 51)
155 | (18037, 155),(17941, 109)
160 | (2424, 160),(2424, 81)
171 | (3449, 171),(3354, 108)
187 | (759, 187),(662, 163)
191 | (16906, 191),(16816, 139)
208 | (28511, 208),(28479, 114)
217 | (19946, 217),(19941, 118)
249 | (45989, 249),(45910, 222)
255 | (24423, 255),(24360, 213)
266 | (22684, 266),(22656, 181)
(15 rows)
RESET enable_indexscan;

View File

@ -1532,25 +1532,25 @@ SELECT cube(array[40,50,60], array[10,20,30])~>1;
SELECT cube(array[10,20,30], array[40,50,60])~>2;
?column?
----------
20
40
(1 row)
SELECT cube(array[40,50,60], array[10,20,30])~>2;
?column?
----------
20
40
(1 row)
SELECT cube(array[10,20,30], array[40,50,60])~>3;
?column?
----------
30
20
(1 row)
SELECT cube(array[40,50,60], array[10,20,30])~>3;
?column?
----------
30
20
(1 row)
SELECT cube(array[40,50,60], array[10,20,30])~>0;
@ -1558,7 +1558,7 @@ ERROR: cube index 0 is out of bounds
SELECT cube(array[40,50,60], array[10,20,30])~>4;
?column?
----------
40
50
(1 row)
SELECT cube(array[40,50,60], array[10,20,30])~>(-1);
@ -1611,25 +1611,28 @@ SELECT c FROM test_cube WHERE c <@ '(3000,1000),(0,0)' ORDER BY c;
(4 rows)
RESET enable_bitmapscan;
-- kNN with index
-- Test kNN
INSERT INTO test_cube VALUES ('(1,1)'), ('(100000)'), ('(0, 100000)'); -- Some corner cases
SET enable_seqscan = false;
-- Test different metrics
SELECT *, c <-> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <-> '(100, 100),(500, 500)'::cube LIMIT 5;
c | dist
-------------------------+------------------
(337, 455),(240, 359) | 0
(1, 1) | 140.007142674936
(759, 187),(662, 163) | 162
(948, 1201),(907, 1156) | 772.000647668122
(1444, 403),(1346, 344) | 846
(369, 1457),(278, 1409) | 909
(5 rows)
SELECT *, c <=> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <=> '(100, 100),(500, 500)'::cube LIMIT 5;
c | dist
-------------------------+------
(337, 455),(240, 359) | 0
(1, 1) | 99
(759, 187),(662, 163) | 162
(948, 1201),(907, 1156) | 656
(1444, 403),(1346, 344) | 846
(369, 1457),(278, 1409) | 909
(5 rows)
SELECT *, c <#> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <#> '(100, 100),(500, 500)'::cube LIMIT 5;
@ -1637,133 +1640,203 @@ SELECT *, c <#> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c
-------------------------+------
(337, 455),(240, 359) | 0
(759, 187),(662, 163) | 162
(1, 1) | 198
(1444, 403),(1346, 344) | 846
(369, 1457),(278, 1409) | 909
(948, 1201),(907, 1156) | 1063
(5 rows)
-- kNN-based sorting
SELECT * FROM test_cube ORDER BY c~>1 LIMIT 15; -- ascending by 1st coordinate of lower left corner
c
---------------------------
(54, 38679),(3, 38602)
(83, 10271),(15, 10265)
(122, 46832),(64, 46762)
(167, 17214),(92, 17184)
(161, 24465),(107, 24374)
(162, 26040),(120, 25963)
(154, 4019),(138, 3990)
(259, 1850),(175, 1820)
(207, 40886),(179, 40879)
(288, 49588),(204, 49571)
(270, 32616),(226, 32607)
(318, 31489),(235, 31404)
(337, 455),(240, 359)
(270, 29508),(264, 29440)
(369, 1457),(278, 1409)
-- Test sorting by coordinates
SELECT c~>1, c FROM test_cube ORDER BY c~>1 LIMIT 15; -- ascending by left bound
?column? | c
----------+---------------------------
0 | (0, 100000)
1 | (1, 1)
3 | (54, 38679),(3, 38602)
15 | (83, 10271),(15, 10265)
64 | (122, 46832),(64, 46762)
92 | (167, 17214),(92, 17184)
107 | (161, 24465),(107, 24374)
120 | (162, 26040),(120, 25963)
138 | (154, 4019),(138, 3990)
175 | (259, 1850),(175, 1820)
179 | (207, 40886),(179, 40879)
204 | (288, 49588),(204, 49571)
226 | (270, 32616),(226, 32607)
235 | (318, 31489),(235, 31404)
240 | (337, 455),(240, 359)
(15 rows)
SELECT * FROM test_cube ORDER BY c~>4 LIMIT 15; -- ascending by 2nd coordinate or upper right corner
c
---------------------------
(30333, 50),(30273, 6)
(43301, 75),(43227, 43)
(19650, 142),(19630, 51)
(2424, 160),(2424, 81)
(3449, 171),(3354, 108)
(18037, 155),(17941, 109)
(28511, 208),(28479, 114)
(19946, 217),(19941, 118)
(16906, 191),(16816, 139)
(759, 187),(662, 163)
(22684, 266),(22656, 181)
(24423, 255),(24360, 213)
(45989, 249),(45910, 222)
(11399, 377),(11360, 294)
(12162, 389),(12103, 309)
SELECT c~>2, c FROM test_cube ORDER BY c~>2 LIMIT 15; -- ascending by right bound
?column? | c
----------+---------------------------
0 | (0, 100000)
1 | (1, 1)
54 | (54, 38679),(3, 38602)
83 | (83, 10271),(15, 10265)
122 | (122, 46832),(64, 46762)
154 | (154, 4019),(138, 3990)
161 | (161, 24465),(107, 24374)
162 | (162, 26040),(120, 25963)
167 | (167, 17214),(92, 17184)
207 | (207, 40886),(179, 40879)
259 | (259, 1850),(175, 1820)
270 | (270, 29508),(264, 29440)
270 | (270, 32616),(226, 32607)
288 | (288, 49588),(204, 49571)
318 | (318, 31489),(235, 31404)
(15 rows)
SELECT * FROM test_cube ORDER BY c~>1 DESC LIMIT 15; -- descending by 1st coordinate of lower left corner
c
-------------------------------
(50027, 49230),(49951, 49214)
(49980, 35004),(49937, 34963)
(49985, 6436),(49927, 6338)
(49999, 27218),(49908, 27176)
(49954, 1340),(49905, 1294)
(49944, 25163),(49902, 25153)
(49981, 34876),(49898, 34786)
(49957, 43390),(49897, 43384)
(49853, 18504),(49848, 18503)
(49902, 41752),(49818, 41746)
(49907, 30225),(49810, 30158)
(49843, 5175),(49808, 5145)
(49887, 24274),(49805, 24184)
(49847, 7128),(49798, 7067)
(49820, 7990),(49771, 7967)
SELECT c~>3, c FROM test_cube ORDER BY c~>3 LIMIT 15; -- ascending by lower bound
?column? | c
----------+---------------------------
0 | (100000)
1 | (1, 1)
6 | (30333, 50),(30273, 6)
43 | (43301, 75),(43227, 43)
51 | (19650, 142),(19630, 51)
81 | (2424, 160),(2424, 81)
108 | (3449, 171),(3354, 108)
109 | (18037, 155),(17941, 109)
114 | (28511, 208),(28479, 114)
118 | (19946, 217),(19941, 118)
139 | (16906, 191),(16816, 139)
163 | (759, 187),(662, 163)
181 | (22684, 266),(22656, 181)
213 | (24423, 255),(24360, 213)
222 | (45989, 249),(45910, 222)
(15 rows)
SELECT * FROM test_cube ORDER BY c~>4 DESC LIMIT 15; -- descending by 2nd coordinate or upper right corner
c
-------------------------------
(36311, 50073),(36258, 49987)
(30746, 50040),(30727, 49992)
(2168, 50012),(2108, 49914)
(21551, 49983),(21492, 49885)
(17954, 49975),(17865, 49915)
(3531, 49962),(3463, 49934)
(19128, 49932),(19112, 49849)
(31287, 49923),(31236, 49913)
(43925, 49912),(43888, 49878)
(29261, 49910),(29247, 49818)
(14913, 49873),(14849, 49836)
(20007, 49858),(19921, 49778)
(38266, 49852),(38233, 49844)
(37595, 49849),(37581, 49834)
(46151, 49848),(46058, 49830)
SELECT c~>4, c FROM test_cube ORDER BY c~>4 LIMIT 15; -- ascending by upper bound
?column? | c
----------+---------------------------
0 | (100000)
1 | (1, 1)
50 | (30333, 50),(30273, 6)
75 | (43301, 75),(43227, 43)
142 | (19650, 142),(19630, 51)
155 | (18037, 155),(17941, 109)
160 | (2424, 160),(2424, 81)
171 | (3449, 171),(3354, 108)
187 | (759, 187),(662, 163)
191 | (16906, 191),(16816, 139)
208 | (28511, 208),(28479, 114)
217 | (19946, 217),(19941, 118)
249 | (45989, 249),(45910, 222)
255 | (24423, 255),(24360, 213)
266 | (22684, 266),(22656, 181)
(15 rows)
-- same thing for index with points
CREATE TABLE test_point(c cube);
INSERT INTO test_point(SELECT cube(array[c->1,c->2,c->3,c->4]) FROM test_cube);
CREATE INDEX ON test_point USING gist(c);
SELECT * FROM test_point ORDER BY c~>1, c~>2 LIMIT 15; -- ascending by 1st then by 2nd coordinate
c
--------------------------
(54, 38679, 3, 38602)
(83, 10271, 15, 10265)
(122, 46832, 64, 46762)
(154, 4019, 138, 3990)
(161, 24465, 107, 24374)
(162, 26040, 120, 25963)
(167, 17214, 92, 17184)
(207, 40886, 179, 40879)
(259, 1850, 175, 1820)
(270, 29508, 264, 29440)
(270, 32616, 226, 32607)
(288, 49588, 204, 49571)
(318, 31489, 235, 31404)
(326, 18837, 285, 18817)
(337, 455, 240, 359)
-- Same queries with sequential scan (should give the same results as above)
RESET enable_seqscan;
SET enable_indexscan = OFF;
SELECT *, c <-> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <-> '(100, 100),(500, 500)'::cube LIMIT 5;
c | dist
-------------------------+------------------
(337, 455),(240, 359) | 0
(1, 1) | 140.007142674936
(759, 187),(662, 163) | 162
(948, 1201),(907, 1156) | 772.000647668122
(1444, 403),(1346, 344) | 846
(5 rows)
SELECT *, c <=> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <=> '(100, 100),(500, 500)'::cube LIMIT 5;
c | dist
-------------------------+------
(337, 455),(240, 359) | 0
(1, 1) | 99
(759, 187),(662, 163) | 162
(948, 1201),(907, 1156) | 656
(1444, 403),(1346, 344) | 846
(5 rows)
SELECT *, c <#> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <#> '(100, 100),(500, 500)'::cube LIMIT 5;
c | dist
-------------------------+------
(337, 455),(240, 359) | 0
(759, 187),(662, 163) | 162
(1, 1) | 198
(1444, 403),(1346, 344) | 846
(369, 1457),(278, 1409) | 909
(5 rows)
SELECT c~>1, c FROM test_cube ORDER BY c~>1 LIMIT 15; -- ascending by left bound
?column? | c
----------+---------------------------
0 | (0, 100000)
1 | (1, 1)
3 | (54, 38679),(3, 38602)
15 | (83, 10271),(15, 10265)
64 | (122, 46832),(64, 46762)
92 | (167, 17214),(92, 17184)
107 | (161, 24465),(107, 24374)
120 | (162, 26040),(120, 25963)
138 | (154, 4019),(138, 3990)
175 | (259, 1850),(175, 1820)
179 | (207, 40886),(179, 40879)
204 | (288, 49588),(204, 49571)
226 | (270, 32616),(226, 32607)
235 | (318, 31489),(235, 31404)
240 | (337, 455),(240, 359)
(15 rows)
SELECT * FROM test_point ORDER BY c~>4 DESC LIMIT 15; -- descending by 1st coordinate
c
------------------------------
(30746, 50040, 30727, 49992)
(36311, 50073, 36258, 49987)
(3531, 49962, 3463, 49934)
(17954, 49975, 17865, 49915)
(2168, 50012, 2108, 49914)
(31287, 49923, 31236, 49913)
(21551, 49983, 21492, 49885)
(43925, 49912, 43888, 49878)
(19128, 49932, 19112, 49849)
(38266, 49852, 38233, 49844)
(14913, 49873, 14849, 49836)
(37595, 49849, 37581, 49834)
(46151, 49848, 46058, 49830)
(29261, 49910, 29247, 49818)
(19233, 49824, 19185, 49794)
SELECT c~>2, c FROM test_cube ORDER BY c~>2 LIMIT 15; -- ascending by right bound
?column? | c
----------+---------------------------
0 | (0, 100000)
1 | (1, 1)
54 | (54, 38679),(3, 38602)
83 | (83, 10271),(15, 10265)
122 | (122, 46832),(64, 46762)
154 | (154, 4019),(138, 3990)
161 | (161, 24465),(107, 24374)
162 | (162, 26040),(120, 25963)
167 | (167, 17214),(92, 17184)
207 | (207, 40886),(179, 40879)
259 | (259, 1850),(175, 1820)
270 | (270, 29508),(264, 29440)
270 | (270, 32616),(226, 32607)
288 | (288, 49588),(204, 49571)
318 | (318, 31489),(235, 31404)
(15 rows)
SELECT c~>3, c FROM test_cube ORDER BY c~>3 LIMIT 15; -- ascending by lower bound
?column? | c
----------+---------------------------
0 | (100000)
1 | (1, 1)
6 | (30333, 50),(30273, 6)
43 | (43301, 75),(43227, 43)
51 | (19650, 142),(19630, 51)
81 | (2424, 160),(2424, 81)
108 | (3449, 171),(3354, 108)
109 | (18037, 155),(17941, 109)
114 | (28511, 208),(28479, 114)
118 | (19946, 217),(19941, 118)
139 | (16906, 191),(16816, 139)
163 | (759, 187),(662, 163)
181 | (22684, 266),(22656, 181)
213 | (24423, 255),(24360, 213)
222 | (45989, 249),(45910, 222)
(15 rows)
SELECT c~>4, c FROM test_cube ORDER BY c~>4 LIMIT 15; -- ascending by upper bound
?column? | c
----------+---------------------------
0 | (100000)
1 | (1, 1)
50 | (30333, 50),(30273, 6)
75 | (43301, 75),(43227, 43)
142 | (19650, 142),(19630, 51)
155 | (18037, 155),(17941, 109)
160 | (2424, 160),(2424, 81)
171 | (3449, 171),(3354, 108)
187 | (759, 187),(662, 163)
191 | (16906, 191),(16816, 139)
208 | (28511, 208),(28479, 114)
217 | (19946, 217),(19941, 118)
249 | (45989, 249),(45910, 222)
255 | (24423, 255),(24360, 213)
266 | (22684, 266),(22656, 181)
(15 rows)
RESET enable_indexscan;

View File

@ -389,20 +389,29 @@ SELECT c FROM test_cube WHERE c <@ '(3000,1000),(0,0)' ORDER BY c;
SELECT c FROM test_cube WHERE c <@ '(3000,1000),(0,0)' ORDER BY c;
RESET enable_bitmapscan;
-- kNN with index
-- Test kNN
INSERT INTO test_cube VALUES ('(1,1)'), ('(100000)'), ('(0, 100000)'); -- Some corner cases
SET enable_seqscan = false;
-- Test different metrics
SELECT *, c <-> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <-> '(100, 100),(500, 500)'::cube LIMIT 5;
SELECT *, c <=> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <=> '(100, 100),(500, 500)'::cube LIMIT 5;
SELECT *, c <#> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <#> '(100, 100),(500, 500)'::cube LIMIT 5;
-- kNN-based sorting
SELECT * FROM test_cube ORDER BY c~>1 LIMIT 15; -- ascending by 1st coordinate of lower left corner
SELECT * FROM test_cube ORDER BY c~>4 LIMIT 15; -- ascending by 2nd coordinate or upper right corner
SELECT * FROM test_cube ORDER BY c~>1 DESC LIMIT 15; -- descending by 1st coordinate of lower left corner
SELECT * FROM test_cube ORDER BY c~>4 DESC LIMIT 15; -- descending by 2nd coordinate or upper right corner
-- Test sorting by coordinates
SELECT c~>1, c FROM test_cube ORDER BY c~>1 LIMIT 15; -- ascending by left bound
SELECT c~>2, c FROM test_cube ORDER BY c~>2 LIMIT 15; -- ascending by right bound
SELECT c~>3, c FROM test_cube ORDER BY c~>3 LIMIT 15; -- ascending by lower bound
SELECT c~>4, c FROM test_cube ORDER BY c~>4 LIMIT 15; -- ascending by upper bound
-- same thing for index with points
CREATE TABLE test_point(c cube);
INSERT INTO test_point(SELECT cube(array[c->1,c->2,c->3,c->4]) FROM test_cube);
CREATE INDEX ON test_point USING gist(c);
SELECT * FROM test_point ORDER BY c~>1, c~>2 LIMIT 15; -- ascending by 1st then by 2nd coordinate
SELECT * FROM test_point ORDER BY c~>4 DESC LIMIT 15; -- descending by 1st coordinate
-- Same queries with sequential scan (should give the same results as above)
RESET enable_seqscan;
SET enable_indexscan = OFF;
SELECT *, c <-> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <-> '(100, 100),(500, 500)'::cube LIMIT 5;
SELECT *, c <=> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <=> '(100, 100),(500, 500)'::cube LIMIT 5;
SELECT *, c <#> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <#> '(100, 100),(500, 500)'::cube LIMIT 5;
SELECT c~>1, c FROM test_cube ORDER BY c~>1 LIMIT 15; -- ascending by left bound
SELECT c~>2, c FROM test_cube ORDER BY c~>2 LIMIT 15; -- ascending by right bound
SELECT c~>3, c FROM test_cube ORDER BY c~>3 LIMIT 15; -- ascending by lower bound
SELECT c~>4, c FROM test_cube ORDER BY c~>4 LIMIT 15; -- ascending by upper bound
RESET enable_indexscan;

View File

@ -186,10 +186,11 @@
<entry><literal>a ~&gt; n</literal></entry>
<entry><type>float8</type></entry>
<entry>
Get <replaceable>n</replaceable>-th coordinate in <quote>normalized</quote> cube
representation, in which the coordinates have been rearranged into
the form <quote>lower left &mdash; upper right</quote>; that is, the
smaller endpoint along each dimension appears first.
Get <replaceable>n</replaceable>-th coordinate of cube in following way:
n = 2 * k - 1 means lower bound of <replaceable>k</replaceable>-th
dimension, n = 2 * k means upper bound of
<replaceable>k</replaceable>-th dimension. This operator is designed
for KNN-GiST support.
</entry>
</row>