Create btree_gist v1.9, in which inet/cidr opclasses aren't default.

btree_gist's gist_inet_ops and gist_cidr_ops opclasses are
fundamentally broken: they rely on an approximate representation of
the inet values and hence sometimes miss rows they should return.
We want to eventually get rid of them altogether, but as the first
step on that journey, we should mark them not-opcdefault.

To do that, roll up the preceding deltas since 1.2 into a new base
script btree_gist--1.9.sql.  This will allow installing 1.9 without
going through a transient situation where gist_inet_ops and
gist_cidr_ops are marked as opcdefault; trying to create them that
way will fail if there's already a matching default opclass in the
core system.  Additionally provide btree_gist--1.8--1.9.sql, so
that a database that's been pg_upgraded from an older version can
be migrated to 1.9.

I noted along the way that commit 57e3c5160 had missed marking the
gist_bool_ops support functions as PARALLEL SAFE.  While that probably
has little harmful effect (since AFAIK we don't check that when
calling index support functions), this seems like a good time to make
things consistent.

Readers will also note that I removed the former habit of installing
some opclass operators/functions with ALTER OPERATOR FAMILY, instead
just rolling them all into the CREATE OPERATOR CLASS steps.  The
comment in btree_gist--1.2.sql that it's necessary to use ALTER for
pg_upgrade reproducibility has been obsolete since we invented the
amadjustmembers infrastructure.  Nowadays, gistadjustmembers will
force all operators and non-required support functions to have "soft"
opfamily dependencies, regardless of whether they are installed by
CREATE or ALTER.

Author: Tom Lane <tgl@sss.pgh.pa.us>
Reviewed-by: Matthias van de Meent <boekewurm+postgres@gmail.com>
Reviewed-by: Heikki Linnakangas <hlinnaka@iki.fi>
Discussion: https://postgr.es/m/2483812.1754072263@sss.pgh.pa.us
This commit is contained in:
Tom Lane
2026-01-08 13:56:08 -05:00
parent 63d1b1cf7f
commit b3b0b45717
9 changed files with 2020 additions and 6 deletions

View File

@ -34,7 +34,8 @@ DATA = btree_gist--1.0--1.1.sql \
btree_gist--1.1--1.2.sql btree_gist--1.2.sql btree_gist--1.2--1.3.sql \
btree_gist--1.3--1.4.sql btree_gist--1.4--1.5.sql \
btree_gist--1.5--1.6.sql btree_gist--1.6--1.7.sql \
btree_gist--1.7--1.8.sql
btree_gist--1.7--1.8.sql btree_gist--1.8--1.9.sql \
btree_gist--1.9.sql
PGFILEDESC = "btree_gist - B-tree equivalent GiST operator classes"
REGRESS = init int2 int4 int8 float4 float8 cash oid timestamp timestamptz \

View File

@ -0,0 +1,40 @@
/* contrib/btree_gist/btree_gist--1.8--1.9.sql */
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "ALTER EXTENSION btree_gist UPDATE TO '1.9'" to load this file. \quit
--
-- Mark gist_inet_ops and gist_cidr_ops opclasses as non-default.
-- This is the first step on the way to eventually removing them.
--
-- There's no SQL command for this, so fake it with a manual update on
-- pg_opclass.
--
DO LANGUAGE plpgsql
$$
DECLARE
my_schema pg_catalog.text := pg_catalog.quote_ident(pg_catalog.current_schema());
old_path pg_catalog.text := pg_catalog.current_setting('search_path');
BEGIN
-- for safety, transiently set search_path to just pg_catalog+pg_temp
PERFORM pg_catalog.set_config('search_path', 'pg_catalog, pg_temp', true);
UPDATE pg_catalog.pg_opclass
SET opcdefault = false
WHERE opcmethod = (SELECT oid FROM pg_catalog.pg_am WHERE amname = 'gist') AND
opcname IN ('gist_inet_ops', 'gist_cidr_ops') AND
opcnamespace = my_schema::pg_catalog.regnamespace;
PERFORM pg_catalog.set_config('search_path', old_path, true);
END
$$;
-- Fix parallel-safety markings overlooked in btree_gist--1.6--1.7.sql.
ALTER FUNCTION gbt_bool_consistent(internal, bool, smallint, oid, internal) PARALLEL SAFE;
ALTER FUNCTION gbt_bool_compress(internal) PARALLEL SAFE;
ALTER FUNCTION gbt_bool_fetch(internal) PARALLEL SAFE;
ALTER FUNCTION gbt_bool_penalty(internal, internal, internal) PARALLEL SAFE;
ALTER FUNCTION gbt_bool_picksplit(internal, internal) PARALLEL SAFE;
ALTER FUNCTION gbt_bool_union(internal, internal) PARALLEL SAFE;
ALTER FUNCTION gbt_bool_same(gbtreekey2, gbtreekey2, internal) PARALLEL SAFE;

File diff suppressed because it is too large Load Diff

View File

@ -1,6 +1,6 @@
# btree_gist extension
comment = 'support for indexing common datatypes in GiST'
default_version = '1.8'
default_version = '1.9'
module_pathname = '$libdir/btree_gist'
relocatable = true
trusted = true

View File

@ -32,7 +32,7 @@ SELECT count(*) FROM cidrtmp WHERE a > '121.111.63.82';
309
(1 row)
CREATE INDEX cidridx ON cidrtmp USING gist ( a );
CREATE INDEX cidridx ON cidrtmp USING gist ( a gist_cidr_ops );
SET enable_seqscan=off;
SELECT count(*) FROM cidrtmp WHERE a < '121.111.63.82'::cidr;
count

View File

@ -32,7 +32,7 @@ SELECT count(*) FROM inettmp WHERE a > '89.225.196.191';
386
(1 row)
CREATE INDEX inetidx ON inettmp USING gist ( a );
CREATE INDEX inetidx ON inettmp USING gist ( a gist_inet_ops );
SET enable_seqscan=off;
SELECT count(*) FROM inettmp WHERE a < '89.225.196.191'::inet;
count

View File

@ -51,6 +51,8 @@ install_data(
'btree_gist--1.5--1.6.sql',
'btree_gist--1.6--1.7.sql',
'btree_gist--1.7--1.8.sql',
'btree_gist--1.8--1.9.sql',
'btree_gist--1.9.sql',
kwargs: contrib_data_args,
)

View File

@ -15,7 +15,7 @@ SELECT count(*) FROM cidrtmp WHERE a >= '121.111.63.82';
SELECT count(*) FROM cidrtmp WHERE a > '121.111.63.82';
CREATE INDEX cidridx ON cidrtmp USING gist ( a );
CREATE INDEX cidridx ON cidrtmp USING gist ( a gist_cidr_ops );
SET enable_seqscan=off;

View File

@ -16,7 +16,7 @@ SELECT count(*) FROM inettmp WHERE a >= '89.225.196.191';
SELECT count(*) FROM inettmp WHERE a > '89.225.196.191';
CREATE INDEX inetidx ON inettmp USING gist ( a );
CREATE INDEX inetidx ON inettmp USING gist ( a gist_inet_ops );
SET enable_seqscan=off;