From de1d042f5979bc1388e9a6d52a4d445342b04932 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Mon, 20 Nov 2017 20:25:18 -0500 Subject: [PATCH] Support index-only scans in contrib/cube and contrib/seg GiST indexes. To do this, we only have to remove the compress and decompress support functions, which have never done anything more than detoasting. In the wake of commit d3a4f89d8, this results in automatically enabling index-only scans, since the core code will now know that the stored representation is the same as the original data (up to detoasting). The only exciting part of this is that ALTER OPERATOR FAMILY lacks a way to drop a support function that was declared as being part of an opclass rather than being loose in the family. For the moment, we'll hack our way to a solution with a manual update of the pg_depend entry type, which is what distinguishes the two cases. Perhaps someday it'll be worth providing a cleaner way to do that, but for now it seems like a very niche problem. Note that the underlying C functions remain, to support use of the shared libraries with older versions of the modules' SQL declarations. Someday we may be able to remove them, but not soon. Andrey Borodin, reviewed by me Discussion: https://postgr.es/m/D0F53A05-4F4A-4DEC-8339-3C069FA0EE11@yandex-team.ru --- contrib/cube/Makefile | 2 +- contrib/cube/cube--1.3--1.4.sql | 45 ++++++++++++++++++++++++++++++++ contrib/cube/cube.control | 2 +- contrib/cube/expected/cube.out | 22 ++++++++++++++++ contrib/cube/expected/cube_2.out | 22 ++++++++++++++++ contrib/cube/sql/cube.sql | 7 +++++ contrib/seg/Makefile | 2 +- contrib/seg/expected/seg.out | 28 ++++++++++++++++++++ contrib/seg/expected/seg_1.out | 28 ++++++++++++++++++++ contrib/seg/seg--1.2--1.3.sql | 45 ++++++++++++++++++++++++++++++++ contrib/seg/seg.control | 2 +- contrib/seg/sql/seg.sql | 9 +++++++ 12 files changed, 210 insertions(+), 4 deletions(-) create mode 100644 contrib/cube/cube--1.3--1.4.sql create mode 100644 contrib/seg/seg--1.2--1.3.sql diff --git a/contrib/cube/Makefile b/contrib/cube/Makefile index 244c1d9bbf..accb7d28a3 100644 --- a/contrib/cube/Makefile +++ b/contrib/cube/Makefile @@ -4,7 +4,7 @@ MODULE_big = cube OBJS= cube.o cubeparse.o $(WIN32RES) EXTENSION = cube -DATA = cube--1.2.sql cube--1.2--1.3.sql \ +DATA = cube--1.2.sql cube--1.2--1.3.sql cube--1.3--1.4.sql \ cube--1.1--1.2.sql cube--1.0--1.1.sql \ cube--unpackaged--1.0.sql PGFILEDESC = "cube - multidimensional cube data type" diff --git a/contrib/cube/cube--1.3--1.4.sql b/contrib/cube/cube--1.3--1.4.sql new file mode 100644 index 0000000000..869820c0c8 --- /dev/null +++ b/contrib/cube/cube--1.3--1.4.sql @@ -0,0 +1,45 @@ +/* contrib/cube/cube--1.3--1.4.sql */ + +-- complain if script is sourced in psql, rather than via ALTER EXTENSION +\echo Use "ALTER EXTENSION cube UPDATE TO '1.4'" to load this file. \quit + +-- +-- Get rid of unnecessary compress and decompress support functions. +-- +-- To be allowed to drop the opclass entry for a support function, +-- we must change the entry's dependency type from 'internal' to 'auto', +-- as though it were a loose member of the opfamily rather than being +-- bound into a particular opclass. There's no SQL command for that, +-- so fake it with a manual update on pg_depend. +-- +UPDATE pg_catalog.pg_depend +SET deptype = 'a' +WHERE classid = 'pg_catalog.pg_amproc'::pg_catalog.regclass + AND objid = + (SELECT objid + FROM pg_catalog.pg_depend + WHERE classid = 'pg_catalog.pg_amproc'::pg_catalog.regclass + AND refclassid = 'pg_catalog.pg_proc'::pg_catalog.regclass + AND (refobjid = 'g_cube_compress(pg_catalog.internal)'::pg_catalog.regprocedure)) + AND refclassid = 'pg_catalog.pg_opclass'::pg_catalog.regclass + AND deptype = 'i'; + +ALTER OPERATOR FAMILY gist_cube_ops USING gist drop function 3 (cube); +ALTER EXTENSION cube DROP function g_cube_compress(pg_catalog.internal); +DROP FUNCTION g_cube_compress(pg_catalog.internal); + +UPDATE pg_catalog.pg_depend +SET deptype = 'a' +WHERE classid = 'pg_catalog.pg_amproc'::pg_catalog.regclass + AND objid = + (SELECT objid + FROM pg_catalog.pg_depend + WHERE classid = 'pg_catalog.pg_amproc'::pg_catalog.regclass + AND refclassid = 'pg_catalog.pg_proc'::pg_catalog.regclass + AND (refobjid = 'g_cube_decompress(pg_catalog.internal)'::pg_catalog.regprocedure)) + AND refclassid = 'pg_catalog.pg_opclass'::pg_catalog.regclass + AND deptype = 'i'; + +ALTER OPERATOR FAMILY gist_cube_ops USING gist drop function 4 (cube); +ALTER EXTENSION cube DROP function g_cube_decompress(pg_catalog.internal); +DROP FUNCTION g_cube_decompress(pg_catalog.internal); diff --git a/contrib/cube/cube.control b/contrib/cube/cube.control index af062d4843..f39a838e3f 100644 --- a/contrib/cube/cube.control +++ b/contrib/cube/cube.control @@ -1,5 +1,5 @@ # cube extension comment = 'data type for multidimensional cubes' -default_version = '1.3' +default_version = '1.4' module_pathname = '$libdir/cube' relocatable = true diff --git a/contrib/cube/expected/cube.out b/contrib/cube/expected/cube.out index 328b3b5f5d..c430b4e1f0 100644 --- a/contrib/cube/expected/cube.out +++ b/contrib/cube/expected/cube.out @@ -1589,6 +1589,28 @@ SELECT * FROM test_cube WHERE c && '(3000,1000),(0,0)' GROUP BY c ORDER BY c; (2424, 160),(2424, 81) (5 rows) +-- Test index-only scans +SET enable_bitmapscan = false; +EXPLAIN (COSTS OFF) +SELECT c FROM test_cube WHERE c <@ '(3000,1000),(0,0)' ORDER BY c; + QUERY PLAN +-------------------------------------------------------- + Sort + Sort Key: c + -> Index Only Scan using test_cube_ix on test_cube + Index Cond: (c <@ '(3000, 1000),(0, 0)'::cube) +(4 rows) + +SELECT c FROM test_cube WHERE c <@ '(3000,1000),(0,0)' ORDER BY c; + c +------------------------- + (337, 455),(240, 359) + (759, 187),(662, 163) + (1444, 403),(1346, 344) + (2424, 160),(2424, 81) +(4 rows) + +RESET enable_bitmapscan; -- kNN with index SELECT *, c <-> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <-> '(100, 100),(500, 500)'::cube LIMIT 5; c | dist diff --git a/contrib/cube/expected/cube_2.out b/contrib/cube/expected/cube_2.out index 1aa5cf2f98..b979c4d6c8 100644 --- a/contrib/cube/expected/cube_2.out +++ b/contrib/cube/expected/cube_2.out @@ -1589,6 +1589,28 @@ SELECT * FROM test_cube WHERE c && '(3000,1000),(0,0)' GROUP BY c ORDER BY c; (2424, 160),(2424, 81) (5 rows) +-- Test index-only scans +SET enable_bitmapscan = false; +EXPLAIN (COSTS OFF) +SELECT c FROM test_cube WHERE c <@ '(3000,1000),(0,0)' ORDER BY c; + QUERY PLAN +-------------------------------------------------------- + Sort + Sort Key: c + -> Index Only Scan using test_cube_ix on test_cube + Index Cond: (c <@ '(3000, 1000),(0, 0)'::cube) +(4 rows) + +SELECT c FROM test_cube WHERE c <@ '(3000,1000),(0,0)' ORDER BY c; + c +------------------------- + (337, 455),(240, 359) + (759, 187),(662, 163) + (1444, 403),(1346, 344) + (2424, 160),(2424, 81) +(4 rows) + +RESET enable_bitmapscan; -- kNN with index SELECT *, c <-> '(100, 100),(500, 500)'::cube as dist FROM test_cube ORDER BY c <-> '(100, 100),(500, 500)'::cube LIMIT 5; c | dist diff --git a/contrib/cube/sql/cube.sql b/contrib/cube/sql/cube.sql index 58ea3ad811..eb24576895 100644 --- a/contrib/cube/sql/cube.sql +++ b/contrib/cube/sql/cube.sql @@ -382,6 +382,13 @@ SELECT * FROM test_cube WHERE c && '(3000,1000),(0,0)' ORDER BY c; -- Test sorting SELECT * FROM test_cube WHERE c && '(3000,1000),(0,0)' GROUP BY c ORDER BY c; +-- Test index-only scans +SET enable_bitmapscan = false; +EXPLAIN (COSTS OFF) +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 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; diff --git a/contrib/seg/Makefile b/contrib/seg/Makefile index 00a5472d3b..41270f84f6 100644 --- a/contrib/seg/Makefile +++ b/contrib/seg/Makefile @@ -4,7 +4,7 @@ MODULE_big = seg OBJS = seg.o segparse.o $(WIN32RES) EXTENSION = seg -DATA = seg--1.1.sql seg--1.1--1.2.sql \ +DATA = seg--1.1.sql seg--1.1--1.2.sql seg--1.2--1.3.sql \ seg--1.0--1.1.sql seg--unpackaged--1.0.sql PGFILEDESC = "seg - line segment data type" diff --git a/contrib/seg/expected/seg.out b/contrib/seg/expected/seg.out index 18010c4d5c..a289dbe5f9 100644 --- a/contrib/seg/expected/seg.out +++ b/contrib/seg/expected/seg.out @@ -930,12 +930,40 @@ SELECT '1'::seg <@ '-1 .. 1'::seg AS bool; CREATE TABLE test_seg (s seg); \copy test_seg from 'data/test_seg.data' CREATE INDEX test_seg_ix ON test_seg USING gist (s); +EXPLAIN (COSTS OFF) +SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; + QUERY PLAN +------------------------------------------------------- + Aggregate + -> Bitmap Heap Scan on test_seg + Recheck Cond: (s @> '1.1e1 .. 11.3'::seg) + -> Bitmap Index Scan on test_seg_ix + Index Cond: (s @> '1.1e1 .. 11.3'::seg) +(5 rows) + SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; count ------- 143 (1 row) +SET enable_bitmapscan = false; +EXPLAIN (COSTS OFF) +SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; + QUERY PLAN +----------------------------------------------------- + Aggregate + -> Index Only Scan using test_seg_ix on test_seg + Index Cond: (s @> '1.1e1 .. 11.3'::seg) +(3 rows) + +SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; + count +------- + 143 +(1 row) + +RESET enable_bitmapscan; -- Test sorting SELECT * FROM test_seg WHERE s @> '11..11.3' GROUP BY s; s diff --git a/contrib/seg/expected/seg_1.out b/contrib/seg/expected/seg_1.out index 566ce394ed..48abb65bb0 100644 --- a/contrib/seg/expected/seg_1.out +++ b/contrib/seg/expected/seg_1.out @@ -930,12 +930,40 @@ SELECT '1'::seg <@ '-1 .. 1'::seg AS bool; CREATE TABLE test_seg (s seg); \copy test_seg from 'data/test_seg.data' CREATE INDEX test_seg_ix ON test_seg USING gist (s); +EXPLAIN (COSTS OFF) +SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; + QUERY PLAN +------------------------------------------------------- + Aggregate + -> Bitmap Heap Scan on test_seg + Recheck Cond: (s @> '1.1e1 .. 11.3'::seg) + -> Bitmap Index Scan on test_seg_ix + Index Cond: (s @> '1.1e1 .. 11.3'::seg) +(5 rows) + SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; count ------- 143 (1 row) +SET enable_bitmapscan = false; +EXPLAIN (COSTS OFF) +SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; + QUERY PLAN +----------------------------------------------------- + Aggregate + -> Index Only Scan using test_seg_ix on test_seg + Index Cond: (s @> '1.1e1 .. 11.3'::seg) +(3 rows) + +SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; + count +------- + 143 +(1 row) + +RESET enable_bitmapscan; -- Test sorting SELECT * FROM test_seg WHERE s @> '11..11.3' GROUP BY s; s diff --git a/contrib/seg/seg--1.2--1.3.sql b/contrib/seg/seg--1.2--1.3.sql new file mode 100644 index 0000000000..cd71a300f6 --- /dev/null +++ b/contrib/seg/seg--1.2--1.3.sql @@ -0,0 +1,45 @@ +/* contrib/seg/seg--1.2--1.3.sql */ + +-- complain if script is sourced in psql, rather than via ALTER EXTENSION +\echo Use "ALTER EXTENSION seg UPDATE TO '1.3'" to load this file. \quit + +-- +-- Get rid of unnecessary compress and decompress support functions. +-- +-- To be allowed to drop the opclass entry for a support function, +-- we must change the entry's dependency type from 'internal' to 'auto', +-- as though it were a loose member of the opfamily rather than being +-- bound into a particular opclass. There's no SQL command for that, +-- so fake it with a manual update on pg_depend. +-- +UPDATE pg_catalog.pg_depend +SET deptype = 'a' +WHERE classid = 'pg_catalog.pg_amproc'::pg_catalog.regclass + AND objid = + (SELECT objid + FROM pg_catalog.pg_depend + WHERE classid = 'pg_catalog.pg_amproc'::pg_catalog.regclass + AND refclassid = 'pg_catalog.pg_proc'::pg_catalog.regclass + AND (refobjid = 'gseg_compress(pg_catalog.internal)'::pg_catalog.regprocedure)) + AND refclassid = 'pg_catalog.pg_opclass'::pg_catalog.regclass + AND deptype = 'i'; + +ALTER OPERATOR FAMILY gist_seg_ops USING gist drop function 3 (seg); +ALTER EXTENSION seg DROP function gseg_compress(pg_catalog.internal); +DROP function gseg_compress(pg_catalog.internal); + +UPDATE pg_catalog.pg_depend +SET deptype = 'a' +WHERE classid = 'pg_catalog.pg_amproc'::pg_catalog.regclass + AND objid = + (SELECT objid + FROM pg_catalog.pg_depend + WHERE classid = 'pg_catalog.pg_amproc'::pg_catalog.regclass + AND refclassid = 'pg_catalog.pg_proc'::pg_catalog.regclass + AND (refobjid = 'gseg_decompress(pg_catalog.internal)'::pg_catalog.regprocedure)) + AND refclassid = 'pg_catalog.pg_opclass'::pg_catalog.regclass + AND deptype = 'i'; + +ALTER OPERATOR FAMILY gist_seg_ops USING gist drop function 4 (seg); +ALTER EXTENSION seg DROP function gseg_decompress(pg_catalog.internal); +DROP function gseg_decompress(pg_catalog.internal); diff --git a/contrib/seg/seg.control b/contrib/seg/seg.control index ba3d092c25..d697cd6c2a 100644 --- a/contrib/seg/seg.control +++ b/contrib/seg/seg.control @@ -1,5 +1,5 @@ # seg extension comment = 'data type for representing line segments or floating-point intervals' -default_version = '1.2' +default_version = '1.3' module_pathname = '$libdir/seg' relocatable = true diff --git a/contrib/seg/sql/seg.sql b/contrib/seg/sql/seg.sql index aa91931474..1d7bad7c37 100644 --- a/contrib/seg/sql/seg.sql +++ b/contrib/seg/sql/seg.sql @@ -216,7 +216,16 @@ CREATE TABLE test_seg (s seg); \copy test_seg from 'data/test_seg.data' CREATE INDEX test_seg_ix ON test_seg USING gist (s); + +EXPLAIN (COSTS OFF) SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; +SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; + +SET enable_bitmapscan = false; +EXPLAIN (COSTS OFF) +SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; +SELECT count(*) FROM test_seg WHERE s @> '11..11.3'; +RESET enable_bitmapscan; -- Test sorting SELECT * FROM test_seg WHERE s @> '11..11.3' GROUP BY s;