summaryrefslogtreecommitdiff
diff options
context:
space:
mode:
authorTom Lane <tgl@sss.pgh.pa.us>2020-08-10 10:44:43 -0400
committerTom Lane <tgl@sss.pgh.pa.us>2020-08-10 10:44:43 -0400
commit96cbfe92d7f0ab5961c75af4d8e71d2f2aecba17 (patch)
tree5515ece20907f95c56483bc16ac9848bf23f9531
parentd112c8755007d8a12b4566b8c09ef81fd154fa10 (diff)
downloadpostgresql-96cbfe92d7f0ab5961c75af4d8e71d2f2aecba17.tar.gz
Make contrib modules' installation scripts more secure.
Hostile objects located within the installation-time search_path could capture references in an extension's installation or upgrade script. If the extension is being installed with superuser privileges, this opens the door to privilege escalation. While such hazards have existed all along, their urgency increases with the v13 "trusted extensions" feature, because that lets a non-superuser control the installation path for a superuser-privileged script. Therefore, make a number of changes to make such situations more secure: * Tweak the construction of the installation-time search_path to ensure that references to objects in pg_catalog can't be subverted; and explicitly add pg_temp to the end of the path to prevent attacks using temporary objects. * Disable check_function_bodies within installation/upgrade scripts, so that any security gaps in SQL-language or PL-language function bodies cannot create a risk of unwanted installation-time code execution. * Adjust lookup of type input/receive functions and join estimator functions to complain if there are multiple candidate functions. This prevents capture of references to functions whose signature is not the first one checked; and it's arguably more user-friendly anyway. * Modify various contrib upgrade scripts to ensure that catalog modification queries are executed with secure search paths. (These are in-place modifications with no extension version changes, since it is the update process itself that is at issue, not the end result.) Extensions that depend on other extensions cannot be made fully secure by these methods alone; therefore, revert the "trusted" marking that commit eb67623c9 applied to earthdistance and hstore_plperl, pending some better solution to that set of issues. Also add documentation around these issues, to help extension authors write secure installation scripts. Patch by me, following an observation by Andres Freund; thanks to Noah Misch for review. Security: CVE-2020-14350
-rw-r--r--contrib/btree_gist/btree_gist--1.1--1.2.sql56
-rw-r--r--contrib/citext/citext--1.1--1.2.sql26
-rw-r--r--contrib/citext/citext--1.2--1.3.sql18
-rw-r--r--contrib/citext/citext--unpackaged--1.0.sql33
-rw-r--r--contrib/cube/cube--1.1--1.2.sql25
-rw-r--r--contrib/earthdistance/earthdistance--1.1.sql2
-rw-r--r--contrib/hstore/hstore--1.1--1.2.sql9
-rw-r--r--contrib/hstore/hstore--1.3--1.4.sql35
-rw-r--r--contrib/intagg/intagg--1.0--1.1.sql14
-rw-r--r--contrib/intarray/intarray--1.1--1.2.sql27
-rw-r--r--contrib/intarray/intarray--unpackaged--1.0.sql20
-rw-r--r--contrib/ltree/ltree--1.0--1.1.sql37
-rw-r--r--contrib/pg_trgm/pg_trgm--1.2--1.3.sql25
-rw-r--r--contrib/pg_trgm/pg_trgm--unpackaged--1.0.sql17
-rw-r--r--contrib/seg/seg--1.0--1.1.sql23
-rw-r--r--doc/src/sgml/earthdistance.sgml27
-rw-r--r--doc/src/sgml/extend.sgml186
-rw-r--r--doc/src/sgml/hstore.sgml9
-rw-r--r--doc/src/sgml/ltree.sgml9
-rw-r--r--doc/src/sgml/ref/create_extension.sgml34
-rw-r--r--doc/src/sgml/release-10.sgml2
-rw-r--r--src/backend/commands/extension.c21
-rw-r--r--src/backend/commands/operatorcmds.c26
-rw-r--r--src/backend/commands/typecmds.c69
24 files changed, 590 insertions, 160 deletions
diff --git a/contrib/btree_gist/btree_gist--1.1--1.2.sql b/contrib/btree_gist/btree_gist--1.1--1.2.sql
index 8487f9bfc8..d5a8c6cf90 100644
--- a/contrib/btree_gist/btree_gist--1.1--1.2.sql
+++ b/contrib/btree_gist/btree_gist--1.1--1.2.sql
@@ -8,56 +8,72 @@
-- wherein the signatures have been updated already. In that case to_regprocedure() will
-- return NULL and no updates will happen.
+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_proc SET
proargtypes = pg_catalog.array_to_string(newtypes::pg_catalog.oid[], ' ')::pg_catalog.oidvector,
pronargs = pg_catalog.array_length(newtypes, 1)
FROM (VALUES
-(NULL::pg_catalog.text, NULL::pg_catalog.regtype[]), -- establish column types
+(NULL::pg_catalog.text, NULL::pg_catalog.text[]), -- establish column types
('gbt_oid_distance(internal,oid,int2,oid)', '{internal,oid,int2,oid,internal}'),
('gbt_oid_union(bytea,internal)', '{internal,internal}'),
-('gbt_oid_same(internal,internal,internal)', '{gbtreekey8,gbtreekey8,internal}'),
+('gbt_oid_same(internal,internal,internal)', '{SCH.gbtreekey8,SCH.gbtreekey8,internal}'),
('gbt_int2_distance(internal,int2,int2,oid)', '{internal,int2,int2,oid,internal}'),
('gbt_int2_union(bytea,internal)', '{internal,internal}'),
-('gbt_int2_same(internal,internal,internal)', '{gbtreekey4,gbtreekey4,internal}'),
+('gbt_int2_same(internal,internal,internal)', '{SCH.gbtreekey4,SCH.gbtreekey4,internal}'),
('gbt_int4_distance(internal,int4,int2,oid)', '{internal,int4,int2,oid,internal}'),
('gbt_int4_union(bytea,internal)', '{internal,internal}'),
-('gbt_int4_same(internal,internal,internal)', '{gbtreekey8,gbtreekey8,internal}'),
+('gbt_int4_same(internal,internal,internal)', '{SCH.gbtreekey8,SCH.gbtreekey8,internal}'),
('gbt_int8_distance(internal,int8,int2,oid)', '{internal,int8,int2,oid,internal}'),
('gbt_int8_union(bytea,internal)', '{internal,internal}'),
-('gbt_int8_same(internal,internal,internal)', '{gbtreekey16,gbtreekey16,internal}'),
+('gbt_int8_same(internal,internal,internal)', '{SCH.gbtreekey16,SCH.gbtreekey16,internal}'),
('gbt_float4_distance(internal,float4,int2,oid)', '{internal,float4,int2,oid,internal}'),
('gbt_float4_union(bytea,internal)', '{internal,internal}'),
-('gbt_float4_same(internal,internal,internal)', '{gbtreekey8,gbtreekey8,internal}'),
+('gbt_float4_same(internal,internal,internal)', '{SCH.gbtreekey8,SCH.gbtreekey8,internal}'),
('gbt_float8_distance(internal,float8,int2,oid)', '{internal,float8,int2,oid,internal}'),
('gbt_float8_union(bytea,internal)', '{internal,internal}'),
-('gbt_float8_same(internal,internal,internal)', '{gbtreekey16,gbtreekey16,internal}'),
+('gbt_float8_same(internal,internal,internal)', '{SCH.gbtreekey16,SCH.gbtreekey16,internal}'),
('gbt_ts_distance(internal,timestamp,int2,oid)', '{internal,timestamp,int2,oid,internal}'),
('gbt_tstz_distance(internal,timestamptz,int2,oid)', '{internal,timestamptz,int2,oid,internal}'),
('gbt_ts_union(bytea,internal)', '{internal,internal}'),
-('gbt_ts_same(internal,internal,internal)', '{gbtreekey16,gbtreekey16,internal}'),
+('gbt_ts_same(internal,internal,internal)', '{SCH.gbtreekey16,SCH.gbtreekey16,internal}'),
('gbt_time_distance(internal,time,int2,oid)', '{internal,time,int2,oid,internal}'),
('gbt_time_union(bytea,internal)', '{internal,internal}'),
-('gbt_time_same(internal,internal,internal)', '{gbtreekey16,gbtreekey16,internal}'),
+('gbt_time_same(internal,internal,internal)', '{SCH.gbtreekey16,SCH.gbtreekey16,internal}'),
('gbt_date_distance(internal,date,int2,oid)', '{internal,date,int2,oid,internal}'),
('gbt_date_union(bytea,internal)', '{internal,internal}'),
-('gbt_date_same(internal,internal,internal)', '{gbtreekey8,gbtreekey8,internal}'),
+('gbt_date_same(internal,internal,internal)', '{SCH.gbtreekey8,SCH.gbtreekey8,internal}'),
('gbt_intv_distance(internal,interval,int2,oid)', '{internal,interval,int2,oid,internal}'),
('gbt_intv_union(bytea,internal)', '{internal,internal}'),
-('gbt_intv_same(internal,internal,internal)', '{gbtreekey32,gbtreekey32,internal}'),
+('gbt_intv_same(internal,internal,internal)', '{SCH.gbtreekey32,SCH.gbtreekey32,internal}'),
('gbt_cash_distance(internal,money,int2,oid)', '{internal,money,int2,oid,internal}'),
('gbt_cash_union(bytea,internal)', '{internal,internal}'),
-('gbt_cash_same(internal,internal,internal)', '{gbtreekey16,gbtreekey16,internal}'),
+('gbt_cash_same(internal,internal,internal)', '{SCH.gbtreekey16,SCH.gbtreekey16,internal}'),
('gbt_macad_union(bytea,internal)', '{internal,internal}'),
-('gbt_macad_same(internal,internal,internal)', '{gbtreekey16,gbtreekey16,internal}'),
+('gbt_macad_same(internal,internal,internal)', '{SCH.gbtreekey16,SCH.gbtreekey16,internal}'),
('gbt_text_union(bytea,internal)', '{internal,internal}'),
-('gbt_text_same(internal,internal,internal)', '{gbtreekey_var,gbtreekey_var,internal}'),
+('gbt_text_same(internal,internal,internal)', '{SCH.gbtreekey_var,SCH.gbtreekey_var,internal}'),
('gbt_bytea_union(bytea,internal)', '{internal,internal}'),
-('gbt_bytea_same(internal,internal,internal)', '{gbtreekey_var,gbtreekey_var,internal}'),
+('gbt_bytea_same(internal,internal,internal)', '{SCH.gbtreekey_var,SCH.gbtreekey_var,internal}'),
('gbt_numeric_union(bytea,internal)', '{internal,internal}'),
-('gbt_numeric_same(internal,internal,internal)', '{gbtreekey_var,gbtreekey_var,internal}'),
+('gbt_numeric_same(internal,internal,internal)', '{SCH.gbtreekey_var,SCH.gbtreekey_var,internal}'),
('gbt_bit_union(bytea,internal)', '{internal,internal}'),
-('gbt_bit_same(internal,internal,internal)', '{gbtreekey_var,gbtreekey_var,internal}'),
+('gbt_bit_same(internal,internal,internal)', '{SCH.gbtreekey_var,SCH.gbtreekey_var,internal}'),
('gbt_inet_union(bytea,internal)', '{internal,internal}'),
-('gbt_inet_same(internal,internal,internal)', '{gbtreekey16,gbtreekey16,internal}')
-) AS update_data (oldproc, newtypes)
-WHERE oid = pg_catalog.to_regprocedure(oldproc);
+('gbt_inet_same(internal,internal,internal)', '{SCH.gbtreekey16,SCH.gbtreekey16,internal}')
+) AS update_data (oldproc, newtypestext),
+LATERAL (
+ SELECT array_agg(replace(typ, 'SCH', my_schema)::regtype) as newtypes FROM unnest(newtypestext) typ
+) ls
+WHERE oid = to_regprocedure(my_schema || '.' || replace(oldproc, 'SCH', my_schema));
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
diff --git a/contrib/citext/citext--1.1--1.2.sql b/contrib/citext/citext--1.1--1.2.sql
index 4f0e4bc719..a8bba860a1 100644
--- a/contrib/citext/citext--1.1--1.2.sql
+++ b/contrib/citext/citext--1.1--1.2.sql
@@ -41,14 +41,28 @@ ALTER FUNCTION replace(citext, citext, citext) PARALLEL SAFE;
ALTER FUNCTION split_part(citext, citext, int) PARALLEL SAFE;
ALTER FUNCTION translate(citext, citext, text) PARALLEL SAFE;
+-- We have to update aggregates the hard way for lack of ALTER support
+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_proc SET proparallel = 's'
-WHERE oid = 'min(citext)'::pg_catalog.regprocedure;
+WHERE oid = (my_schema || '.min(' || my_schema || '.citext)')::pg_catalog.regprocedure;
UPDATE pg_proc SET proparallel = 's'
-WHERE oid = 'max(citext)'::pg_catalog.regprocedure;
+WHERE oid = (my_schema || '.max(' || my_schema || '.citext)')::pg_catalog.regprocedure;
+
+UPDATE pg_aggregate SET aggcombinefn = (my_schema || '.citext_smaller')::regproc
+WHERE aggfnoid = (my_schema || '.max(' || my_schema || '.citext)')::pg_catalog.regprocedure;
-UPDATE pg_aggregate SET aggcombinefn = 'citext_smaller'
-WHERE aggfnoid = 'max(citext)'::pg_catalog.regprocedure;
+UPDATE pg_aggregate SET aggcombinefn = (my_schema || '.citext_larger')::regproc
+WHERE aggfnoid = (my_schema || '.max(' || my_schema || '.citext)')::pg_catalog.regprocedure;
-UPDATE pg_aggregate SET aggcombinefn = 'citext_larger'
-WHERE aggfnoid = 'max(citext)'::pg_catalog.regprocedure;
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
diff --git a/contrib/citext/citext--1.2--1.3.sql b/contrib/citext/citext--1.2--1.3.sql
index 4ab867915c..24a71452c6 100644
--- a/contrib/citext/citext--1.2--1.3.sql
+++ b/contrib/citext/citext--1.2--1.3.sql
@@ -3,5 +3,19 @@
-- complain if script is sourced in psql, rather than via ALTER EXTENSION
\echo Use "ALTER EXTENSION citext UPDATE TO '1.3'" to load this file. \quit
-UPDATE pg_aggregate SET aggcombinefn = 'citext_smaller'
-WHERE aggfnoid = 'min(citext)'::pg_catalog.regprocedure;
+-- We have to update aggregates the hard way for lack of ALTER support
+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_aggregate SET aggcombinefn = (my_schema || '.citext_smaller')::regproc
+WHERE aggfnoid = (my_schema || '.min(' || my_schema || '.citext)')::pg_catalog.regprocedure;
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
diff --git a/contrib/citext/citext--unpackaged--1.0.sql b/contrib/citext/citext--unpackaged--1.0.sql
index ef6d6b0639..4061a0aeff 100644
--- a/contrib/citext/citext--unpackaged--1.0.sql
+++ b/contrib/citext/citext--unpackaged--1.0.sql
@@ -89,8 +89,17 @@ ALTER EXTENSION citext ADD function translate(citext,citext,text);
-- default collation is pinned.
--
+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);
+
WITH RECURSIVE typeoids(typoid) AS
- ( SELECT 'citext'::pg_catalog.regtype UNION
+ ( SELECT (my_schema || '.citext')::pg_catalog.regtype UNION
SELECT oid FROM pg_catalog.pg_type, typeoids
WHERE typelem = typoid OR typbasetype = typoid )
UPDATE pg_catalog.pg_type SET typcollation = 100
@@ -98,7 +107,7 @@ FROM typeoids
WHERE oid = typeoids.typoid;
WITH RECURSIVE typeoids(typoid) AS
- ( SELECT 'citext'::pg_catalog.regtype UNION
+ ( SELECT (my_schema || '.citext')::pg_catalog.regtype UNION
SELECT oid FROM pg_catalog.pg_type, typeoids
WHERE typelem = typoid OR typbasetype = typoid )
UPDATE pg_catalog.pg_attribute SET attcollation = 100
@@ -113,7 +122,7 @@ UPDATE pg_catalog.pg_index SET indcollation =
pg_catalog.regexp_replace(indcollation::pg_catalog.text, '^0', '100')::pg_catalog.oidvector
WHERE indclass[0] IN (
WITH RECURSIVE typeoids(typoid) AS
- ( SELECT 'citext'::pg_catalog.regtype UNION
+ ( SELECT (my_schema || '.citext')::pg_catalog.regtype UNION
SELECT oid FROM pg_catalog.pg_type, typeoids
WHERE typelem = typoid OR typbasetype = typoid )
SELECT oid FROM pg_catalog.pg_opclass, typeoids
@@ -124,7 +133,7 @@ UPDATE pg_catalog.pg_index SET indcollation =
pg_catalog.regexp_replace(indcollation::pg_catalog.text, E'^(\\d+) 0', E'\\1 100')::pg_catalog.oidvector
WHERE indclass[1] IN (
WITH RECURSIVE typeoids(typoid) AS
- ( SELECT 'citext'::pg_catalog.regtype UNION
+ ( SELECT (my_schema || '.citext')::pg_catalog.regtype UNION
SELECT oid FROM pg_catalog.pg_type, typeoids
WHERE typelem = typoid OR typbasetype = typoid )
SELECT oid FROM pg_catalog.pg_opclass, typeoids
@@ -135,7 +144,7 @@ UPDATE pg_catalog.pg_index SET indcollation =
pg_catalog.regexp_replace(indcollation::pg_catalog.text, E'^(\\d+ \\d+) 0', E'\\1 100')::pg_catalog.oidvector
WHERE indclass[2] IN (
WITH RECURSIVE typeoids(typoid) AS
- ( SELECT 'citext'::pg_catalog.regtype UNION
+ ( SELECT (my_schema || '.citext')::pg_catalog.regtype UNION
SELECT oid FROM pg_catalog.pg_type, typeoids
WHERE typelem = typoid OR typbasetype = typoid )
SELECT oid FROM pg_catalog.pg_opclass, typeoids
@@ -146,7 +155,7 @@ UPDATE pg_catalog.pg_index SET indcollation =
pg_catalog.regexp_replace(indcollation::pg_catalog.text, E'^(\\d+ \\d+ \\d+) 0', E'\\1 100')::pg_catalog.oidvector
WHERE indclass[3] IN (
WITH RECURSIVE typeoids(typoid) AS
- ( SELECT 'citext'::pg_catalog.regtype UNION
+ ( SELECT (my_schema || '.citext')::pg_catalog.regtype UNION
SELECT oid FROM pg_catalog.pg_type, typeoids
WHERE typelem = typoid OR typbasetype = typoid )
SELECT oid FROM pg_catalog.pg_opclass, typeoids
@@ -157,7 +166,7 @@ UPDATE pg_catalog.pg_index SET indcollation =
pg_catalog.regexp_replace(indcollation::pg_catalog.text, E'^(\\d+ \\d+ \\d+ \\d+) 0', E'\\1 100')::pg_catalog.oidvector
WHERE indclass[4] IN (
WITH RECURSIVE typeoids(typoid) AS
- ( SELECT 'citext'::pg_catalog.regtype UNION
+ ( SELECT (my_schema || '.citext')::pg_catalog.regtype UNION
SELECT oid FROM pg_catalog.pg_type, typeoids
WHERE typelem = typoid OR typbasetype = typoid )
SELECT oid FROM pg_catalog.pg_opclass, typeoids
@@ -168,7 +177,7 @@ UPDATE pg_catalog.pg_index SET indcollation =
pg_catalog.regexp_replace(indcollation::pg_catalog.text, E'^(\\d+ \\d+ \\d+ \\d+ \\d+) 0', E'\\1 100')::pg_catalog.oidvector
WHERE indclass[5] IN (
WITH RECURSIVE typeoids(typoid) AS
- ( SELECT 'citext'::pg_catalog.regtype UNION
+ ( SELECT (my_schema || '.citext')::pg_catalog.regtype UNION
SELECT oid FROM pg_catalog.pg_type, typeoids
WHERE typelem = typoid OR typbasetype = typoid )
SELECT oid FROM pg_catalog.pg_opclass, typeoids
@@ -179,7 +188,7 @@ UPDATE pg_catalog.pg_index SET indcollation =
pg_catalog.regexp_replace(indcollation::pg_catalog.text, E'^(\\d+ \\d+ \\d+ \\d+ \\d+ \\d+) 0', E'\\1 100')::pg_catalog.oidvector
WHERE indclass[6] IN (
WITH RECURSIVE typeoids(typoid) AS
- ( SELECT 'citext'::pg_catalog.regtype UNION
+ ( SELECT (my_schema || '.citext')::pg_catalog.regtype UNION
SELECT oid FROM pg_catalog.pg_type, typeoids
WHERE typelem = typoid OR typbasetype = typoid )
SELECT oid FROM pg_catalog.pg_opclass, typeoids
@@ -190,7 +199,7 @@ UPDATE pg_catalog.pg_index SET indcollation =
pg_catalog.regexp_replace(indcollation::pg_catalog.text, E'^(\\d+ \\d+ \\d+ \\d+ \\d+ \\d+ \\d+) 0', E'\\1 100')::pg_catalog.oidvector
WHERE indclass[7] IN (
WITH RECURSIVE typeoids(typoid) AS
- ( SELECT 'citext'::pg_catalog.regtype UNION
+ ( SELECT (my_schema || '.citext')::pg_catalog.regtype UNION
SELECT oid FROM pg_catalog.pg_type, typeoids
WHERE typelem = typoid OR typbasetype = typoid )
SELECT oid FROM pg_catalog.pg_opclass, typeoids
@@ -198,3 +207,7 @@ WHERE indclass[7] IN (
);
-- somewhat arbitrarily, we assume no citext indexes have more than 8 columns
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
diff --git a/contrib/cube/cube--1.1--1.2.sql b/contrib/cube/cube--1.1--1.2.sql
index 64a531e8b4..76aba239e5 100644
--- a/contrib/cube/cube--1.1--1.2.sql
+++ b/contrib/cube/cube--1.1--1.2.sql
@@ -7,16 +7,31 @@
-- We use to_regprocedure() so that query doesn't fail if run against 9.6beta1 definitions,
-- wherein the signatures have been updated already. In that case to_regprocedure() will
-- return NULL and no updates will happen.
+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_proc SET
proargtypes = pg_catalog.array_to_string(newtypes::pg_catalog.oid[], ' ')::pg_catalog.oidvector,
pronargs = pg_catalog.array_length(newtypes, 1)
FROM (VALUES
-(NULL::pg_catalog.text, NULL::pg_catalog.regtype[]), -- establish column types
-('g_cube_consistent(internal,cube,int4,oid,internal)', '{internal,cube,int2,oid,internal}'),
-('g_cube_distance(internal,cube,smallint,oid)', '{internal,cube,smallint,oid,internal}')
-) AS update_data (oldproc, newtypes)
-WHERE oid = pg_catalog.to_regprocedure(oldproc);
+(NULL::pg_catalog.text, NULL::pg_catalog.text[]), -- establish column types
+('g_cube_consistent(internal,SCH.cube,int4,oid,internal)', '{internal,SCH.cube,int2,oid,internal}'),
+('g_cube_distance(internal,SCH.cube,smallint,oid)', '{internal,SCH.cube,smallint,oid,internal}')
+) AS update_data (oldproc, newtypestext),
+LATERAL (
+ SELECT array_agg(replace(typ, 'SCH', my_schema)::regtype) as newtypes FROM unnest(newtypestext) typ
+) ls
+WHERE oid = to_regprocedure(my_schema || '.' || replace(oldproc, 'SCH', my_schema));
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
ALTER FUNCTION cube_in(cstring) PARALLEL SAFE;
ALTER FUNCTION cube(float8[], float8[]) PARALLEL SAFE;
diff --git a/contrib/earthdistance/earthdistance--1.1.sql b/contrib/earthdistance/earthdistance--1.1.sql
index 9136a54a7b..9ef20ab848 100644
--- a/contrib/earthdistance/earthdistance--1.1.sql
+++ b/contrib/earthdistance/earthdistance--1.1.sql
@@ -31,7 +31,7 @@ CREATE DOMAIN earth AS cube
CONSTRAINT not_point check(cube_is_point(value))
CONSTRAINT not_3d check(cube_dim(value) <= 3)
CONSTRAINT on_surface check(abs(cube_distance(value, '(0)'::cube) /
- earth() - 1) < '10e-7'::float8);
+ earth() - '1'::float8) < '10e-7'::float8);
CREATE FUNCTION sec_to_gc(float8)
RETURNS float8
diff --git a/contrib/hstore/hstore--1.1--1.2.sql b/contrib/hstore/hstore--1.1--1.2.sql
index a868ffe48e..cc69fc7f80 100644
--- a/contrib/hstore/hstore--1.1--1.2.sql
+++ b/contrib/hstore/hstore--1.1--1.2.sql
@@ -9,10 +9,13 @@
-- dependent on the extension.
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);
PERFORM 1
FROM pg_proc p
@@ -27,6 +30,7 @@ BEGIN
IF NOT FOUND
THEN
+ PERFORM pg_catalog.set_config('search_path', old_path, true);
CREATE FUNCTION hstore_to_json(hstore)
RETURNS json
@@ -43,6 +47,7 @@ BEGIN
END IF;
+PERFORM pg_catalog.set_config('search_path', old_path, true);
END;
$$;
diff --git a/contrib/hstore/hstore--1.3--1.4.sql b/contrib/hstore/hstore--1.3--1.4.sql
index d68956bb94..53f26f9fb8 100644
--- a/contrib/hstore/hstore--1.3--1.4.sql
+++ b/contrib/hstore/hstore--1.3--1.4.sql
@@ -7,23 +7,38 @@
-- We use to_regprocedure() so that query doesn't fail if run against 9.6beta1 definitions,
-- wherein the signatures have been updated already. In that case to_regprocedure() will
-- return NULL and no updates will happen.
+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_proc SET
proargtypes = pg_catalog.array_to_string(newtypes::pg_catalog.oid[], ' ')::pg_catalog.oidvector,
pronargs = pg_catalog.array_length(newtypes, 1)
FROM (VALUES
-(NULL::pg_catalog.text, NULL::pg_catalog.regtype[]), -- establish column types
-('ghstore_same(internal,internal,internal)', '{ghstore,ghstore,internal}'),
-('ghstore_consistent(internal,internal,int4,oid,internal)', '{internal,hstore,int2,oid,internal}'),
-('gin_extract_hstore(internal,internal)', '{hstore,internal}'),
-('gin_extract_hstore_query(internal,internal,int2,internal,internal)', '{hstore,internal,int2,internal,internal}'),
-('gin_consistent_hstore(internal,int2,internal,int4,internal,internal)', '{internal,int2,hstore,int4,internal,internal}')
-) AS update_data (oldproc, newtypes)
-WHERE oid = pg_catalog.to_regprocedure(oldproc);
+(NULL::pg_catalog.text, NULL::pg_catalog.text[]), -- establish column types
+('ghstore_same(internal,internal,internal)', '{SCH.ghstore,SCH.ghstore,internal}'),
+('ghstore_consistent(internal,internal,int4,oid,internal)', '{internal,SCH.hstore,int2,oid,internal}'),
+('gin_extract_hstore(internal,internal)', '{SCH.hstore,internal}'),
+('gin_extract_hstore_query(internal,internal,int2,internal,internal)', '{SCH.hstore,internal,int2,internal,internal}'),
+('gin_consistent_hstore(internal,int2,internal,int4,internal,internal)', '{internal,int2,SCH.hstore,int4,internal,internal}')
+) AS update_data (oldproc, newtypestext),
+LATERAL (
+ SELECT array_agg(replace(typ, 'SCH', my_schema)::regtype) as newtypes FROM unnest(newtypestext) typ
+) ls
+WHERE oid = to_regprocedure(my_schema || '.' || replace(oldproc, 'SCH', my_schema));
UPDATE pg_catalog.pg_proc SET
- prorettype = 'ghstore'::pg_catalog.regtype
-WHERE oid = pg_catalog.to_regprocedure('ghstore_union(internal,internal)');
+ prorettype = (my_schema || '.ghstore')::pg_catalog.regtype
+WHERE oid = pg_catalog.to_regprocedure((my_schema || '.ghstore_union(internal,internal)'));
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
ALTER FUNCTION hstore_in(cstring) PARALLEL SAFE;
ALTER FUNCTION hstore_out(hstore) PARALLEL SAFE;
diff --git a/contrib/intagg/intagg--1.0--1.1.sql b/contrib/intagg/intagg--1.0--1.1.sql
index b2a2820b0c..c0cc17a033 100644
--- a/contrib/intagg/intagg--1.0--1.1.sql
+++ b/contrib/intagg/intagg--1.0--1.1.sql
@@ -6,6 +6,18 @@
ALTER FUNCTION int_agg_state(internal, int4) PARALLEL SAFE;
ALTER FUNCTION int_agg_final_array(internal) PARALLEL SAFE;
ALTER FUNCTION int_array_enum(int4[]) PARALLEL SAFE;
+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_proc SET proparallel = 's'
-WHERE oid = 'int_array_aggregate(int4)'::pg_catalog.regprocedure;
+WHERE oid = (my_schema || '.int_array_aggregate(int4)')::pg_catalog.regprocedure;
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
diff --git a/contrib/intarray/intarray--1.1--1.2.sql b/contrib/intarray/intarray--1.1--1.2.sql
index 468f245ece..919340ef01 100644
--- a/contrib/intarray/intarray--1.1--1.2.sql
+++ b/contrib/intarray/intarray--1.1--1.2.sql
@@ -7,23 +7,38 @@
-- We use to_regprocedure() so that query doesn't fail if run against 9.6beta1 definitions,
-- wherein the signatures have been updated already. In that case to_regprocedure() will
-- return NULL and no updates will happen.
+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_proc SET
proargtypes = pg_catalog.array_to_string(newtypes::pg_catalog.oid[], ' ')::pg_catalog.oidvector,
pronargs = pg_catalog.array_length(newtypes, 1)
FROM (VALUES
-(NULL::pg_catalog.text, NULL::pg_catalog.regtype[]), -- establish column types
+(NULL::pg_catalog.text, NULL::pg_catalog.text[]), -- establish column types
('g_int_consistent(internal,_int4,int4,oid,internal)', '{internal,_int4,int2,oid,internal}'),
('g_intbig_consistent(internal,internal,int4,oid,internal)', '{internal,_int4,int2,oid,internal}'),
-('g_intbig_same(internal,internal,internal)', '{intbig_gkey,intbig_gkey,internal}'),
+('g_intbig_same(internal,internal,internal)', '{SCH.intbig_gkey,SCH.intbig_gkey,internal}'),
('ginint4_queryextract(internal,internal,int2,internal,internal,internal,internal)', '{_int4,internal,int2,internal,internal,internal,internal}'),
('ginint4_consistent(internal,int2,internal,int4,internal,internal,internal,internal)', '{internal,int2,_int4,int4,internal,internal,internal,internal}')
-) AS update_data (oldproc, newtypes)
-WHERE oid = pg_catalog.to_regprocedure(oldproc);
+) AS update_data (oldproc, newtypestext),
+LATERAL (
+ SELECT array_agg(replace(typ, 'SCH', my_schema)::regtype) as newtypes FROM unnest(newtypestext) typ
+) ls
+WHERE oid = to_regprocedure(my_schema || '.' || replace(oldproc, 'SCH', my_schema));
UPDATE pg_catalog.pg_proc SET
- prorettype = 'intbig_gkey'::pg_catalog.regtype
-WHERE oid = pg_catalog.to_regprocedure('g_intbig_union(internal,internal)');
+ prorettype = (my_schema || '.intbig_gkey')::pg_catalog.regtype
+WHERE oid = pg_catalog.to_regprocedure(my_schema || '.g_intbig_union(internal,internal)');
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
ALTER FUNCTION bqarr_in(cstring) PARALLEL SAFE;
ALTER FUNCTION bqarr_out(query_int) PARALLEL SAFE;
diff --git a/contrib/intarray/intarray--unpackaged--1.0.sql b/contrib/intarray/intarray--unpackaged--1.0.sql
index 63814cef98..7f1bef60b1 100644
--- a/contrib/intarray/intarray--unpackaged--1.0.sql
+++ b/contrib/intarray/intarray--unpackaged--1.0.sql
@@ -84,13 +84,23 @@ ALTER EXTENSION intarray ADD function ginint4_consistent(internal,smallint,inter
-- entries. This is ugly as can be, but there's no other way to do it
-- while preserving the identities (OIDs) of the functions.
+DO LANGUAGE plpgsql
+$$
+DECLARE
+ my_schema_unquoted pg_catalog.text := pg_catalog.current_schema();
+ 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_proc
SET pronargs = 7, proargtypes = '2281 2281 21 2281 2281 2281 2281'
-WHERE oid = 'ginint4_queryextract(internal,internal,smallint,internal,internal)'::pg_catalog.regprocedure;
+WHERE oid = (my_schema || '.ginint4_queryextract(internal,internal,smallint,internal,internal)')::pg_catalog.regprocedure;
UPDATE pg_catalog.pg_proc
SET pronargs = 8, proargtypes = '2281 21 2281 23 2281 2281 2281 2281'
-WHERE oid = 'ginint4_consistent(internal,smallint,internal,integer,internal,internal)'::pg_catalog.regprocedure;
+WHERE oid = (my_schema || '.ginint4_consistent(internal,smallint,internal,integer,internal,internal)')::pg_catalog.regprocedure;
-- intarray also relies on the core function ginarrayextract, which changed
-- signature in 9.1. To support upgrading, pg_catalog contains entries
@@ -104,8 +114,12 @@ SET amproc = 'pg_catalog.ginarrayextract(anyarray,internal,internal)'::pg_catalo
WHERE amprocfamily =
(SELECT oid FROM pg_catalog.pg_opfamily WHERE opfname = 'gin__int_ops' AND
opfnamespace = (SELECT oid FROM pg_catalog.pg_namespace
- WHERE nspname = pg_catalog.current_schema()))
+ WHERE nspname = my_schema_unquoted))
AND amproclefttype = 'integer[]'::pg_catalog.regtype
AND amprocrighttype = 'integer[]'::pg_catalog.regtype
AND amprocnum = 2
AND amproc = 'pg_catalog.ginarrayextract(anyarray,internal)'::pg_catalog.regprocedure;
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
diff --git a/contrib/ltree/ltree--1.0--1.1.sql b/contrib/ltree/ltree--1.0--1.1.sql
index 155751aa3a..2ce6f5adbc 100644
--- a/contrib/ltree/ltree--1.0--1.1.sql
+++ b/contrib/ltree/ltree--1.0--1.1.sql
@@ -7,26 +7,41 @@
-- We use to_regprocedure() so that query doesn't fail if run against 9.6beta1 definitions,
-- wherein the signatures have been updated already. In that case to_regprocedure() will
-- return NULL and no updates will happen.
+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_proc SET
proargtypes = pg_catalog.array_to_string(newtypes::pg_catalog.oid[], ' ')::pg_catalog.oidvector,
pronargs = pg_catalog.array_length(newtypes, 1)
FROM (VALUES
-(NULL::pg_catalog.text, NULL::pg_catalog.regtype[]), -- establish column types
-('ltree_consistent(internal,internal,int2,oid,internal)', '{internal,ltree,int2,oid,internal}'),
-('ltree_same(internal,internal,internal)', '{ltree_gist,ltree_gist,internal}'),
-('_ltree_consistent(internal,internal,int2,oid,internal)', '{internal,_ltree,int2,oid,internal}'),
-('_ltree_same(internal,internal,internal)', '{ltree_gist,ltree_gist,internal}')
-) AS update_data (oldproc, newtypes)
-WHERE oid = pg_catalog.to_regprocedure(oldproc);
+(NULL::pg_catalog.text, NULL::pg_catalog.text[]), -- establish column types
+('ltree_consistent(internal,internal,int2,oid,internal)', '{internal,SCH.ltree,int2,oid,internal}'),
+('ltree_same(internal,internal,internal)', '{SCH.ltree_gist,SCH.ltree_gist,internal}'),
+('_ltree_consistent(internal,internal,int2,oid,internal)', '{internal,SCH._ltree,int2,oid,internal}'),
+('_ltree_same(internal,internal,internal)', '{SCH.ltree_gist,SCH.ltree_gist,internal}')
+) AS update_data (oldproc, newtypestext),
+LATERAL (
+ SELECT array_agg(replace(typ, 'SCH', my_schema)::regtype) as newtypes FROM unnest(newtypestext) typ
+) ls
+WHERE oid = to_regprocedure(my_schema || '.' || replace(oldproc, 'SCH', my_schema));
UPDATE pg_catalog.pg_proc SET
- prorettype = 'ltree_gist'::pg_catalog.regtype
-WHERE oid = pg_catalog.to_regprocedure('ltree_union(internal,internal)');
+ prorettype = (my_schema || '.ltree_gist')::pg_catalog.regtype
+WHERE oid = pg_catalog.to_regprocedure(my_schema || '.ltree_union(internal,internal)');
UPDATE pg_catalog.pg_proc SET
- prorettype = 'ltree_gist'::pg_catalog.regtype
-WHERE oid = pg_catalog.to_regprocedure('_ltree_union(internal,internal)');
+ prorettype = (my_schema || '.ltree_gist')::pg_catalog.regtype
+WHERE oid = pg_catalog.to_regprocedure(my_schema || '._ltree_union(internal,internal)');
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
ALTER FUNCTION ltree_in(cstring) PARALLEL SAFE;
ALTER FUNCTION ltree_out(ltree) PARALLEL SAFE;
diff --git a/contrib/pg_trgm/pg_trgm--1.2--1.3.sql b/contrib/pg_trgm/pg_trgm--1.2--1.3.sql
index b082dcd8d8..8dc772c407 100644
--- a/contrib/pg_trgm/pg_trgm--1.2--1.3.sql
+++ b/contrib/pg_trgm/pg_trgm--1.2--1.3.sql
@@ -7,21 +7,36 @@
-- We use to_regprocedure() so that query doesn't fail if run against 9.6beta1 definitions,
-- wherein the signatures have been updated already. In that case to_regprocedure() will
-- return NULL and no updates will happen.
+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_proc SET
proargtypes = pg_catalog.array_to_string(newtypes::pg_catalog.oid[], ' ')::pg_catalog.oidvector,
pronargs = pg_catalog.array_length(newtypes, 1)
FROM (VALUES
-(NULL::pg_catalog.text, NULL::pg_catalog.regtype[]), -- establish column types
+(NULL::pg_catalog.text, NULL::pg_catalog.text[]), -- establish column types
('gtrgm_consistent(internal,text,int4,oid,internal)', '{internal,text,int2,oid,internal}'),
('gtrgm_distance(internal,text,int4,oid)', '{internal,text,int2,oid,internal}'),
('gtrgm_union(bytea,internal)', '{internal,internal}')
-) AS update_data (oldproc, newtypes)
-WHERE oid = pg_catalog.to_regprocedure(oldproc);
+) AS update_data (oldproc, newtypestext),
+LATERAL (
+ SELECT array_agg(replace(typ, 'SCH', my_schema)::regtype) as newtypes FROM unnest(newtypestext) typ
+) ls
+WHERE oid = to_regprocedure(my_schema || '.' || replace(oldproc, 'SCH', my_schema));
UPDATE pg_catalog.pg_proc SET
- prorettype = 'gtrgm'::pg_catalog.regtype
-WHERE oid = pg_catalog.to_regprocedure('gtrgm_union(internal,internal)');
+ prorettype = (my_schema || '.gtrgm')::pg_catalog.regtype
+WHERE oid = pg_catalog.to_regprocedure(my_schema || '.gtrgm_union(internal,internal)');
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
ALTER FUNCTION set_limit(float4) PARALLEL UNSAFE;
ALTER FUNCTION show_limit() PARALLEL SAFE;
diff --git a/contrib/pg_trgm/pg_trgm--unpackaged--1.0.sql b/contrib/pg_trgm/pg_trgm--unpackaged--1.0.sql
index d3eab97d41..99444d37c3 100644
--- a/contrib/pg_trgm/pg_trgm--unpackaged--1.0.sql
+++ b/contrib/pg_trgm/pg_trgm--unpackaged--1.0.sql
@@ -57,13 +57,26 @@ LANGUAGE C IMMUTABLE STRICT;
-- entries. This is ugly as can be, but there's no other way to do it
-- while preserving the identities (OIDs) of the functions.
+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_proc
SET pronargs = 7, proargtypes = '25 2281 21 2281 2281 2281 2281'
-WHERE oid = 'gin_extract_query_trgm(text,internal,int2,internal,internal)'::pg_catalog.regprocedure;
+WHERE oid = (my_schema || '.gin_extract_query_trgm(text,internal,int2,internal,internal)')::pg_catalog.regprocedure;
UPDATE pg_catalog.pg_proc
SET pronargs = 8, proargtypes = '2281 21 25 23 2281 2281 2281 2281'
-WHERE oid = 'gin_trgm_consistent(internal,smallint,text,integer,internal,internal)'::pg_catalog.regprocedure;
+WHERE oid = (my_schema || '.gin_trgm_consistent(internal,smallint,text,integer,internal,internal)')::pg_catalog.regprocedure;
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
-- These were not in 9.0:
diff --git a/contrib/seg/seg--1.0--1.1.sql b/contrib/seg/seg--1.0--1.1.sql
index 2dcd4d4280..ae6cb2fba8 100644
--- a/contrib/seg/seg--1.0--1.1.sql
+++ b/contrib/seg/seg--1.0--1.1.sql
@@ -7,15 +7,30 @@
-- We use to_regprocedure() so that query doesn't fail if run against 9.6beta1 definitions,
-- wherein the signatures have been updated already. In that case to_regprocedure() will
-- return NULL and no updates will happen.
+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_proc SET
proargtypes = pg_catalog.array_to_string(newtypes::pg_catalog.oid[], ' ')::pg_catalog.oidvector,
pronargs = pg_catalog.array_length(newtypes, 1)
FROM (VALUES
-(NULL::pg_catalog.text, NULL::pg_catalog.regtype[]), -- establish column types
-('gseg_consistent(internal,seg,int4,oid,internal)', '{internal,seg,int2,oid,internal}')
-) AS update_data (oldproc, newtypes)
-WHERE oid = pg_catalog.to_regprocedure(oldproc);
+(NULL::pg_catalog.text, NULL::pg_catalog.text[]), -- establish column types
+('gseg_consistent(internal,SCH.seg,int4,oid,internal)', '{internal,SCH.seg,int2,oid,internal}')
+) AS update_data (oldproc, newtypestext),
+LATERAL (
+ SELECT array_agg(replace(typ, 'SCH', my_schema)::regtype) as newtypes FROM unnest(newtypestext) typ
+) ls
+WHERE oid = to_regprocedure(my_schema || '.' || replace(oldproc, 'SCH', my_schema));
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
ALTER FUNCTION seg_in(cstring) PARALLEL SAFE;
ALTER FUNCTION seg_out(seg) PARALLEL SAFE;
diff --git a/doc/src/sgml/earthdistance.sgml b/doc/src/sgml/earthdistance.sgml
index 2b6df5fee5..d62450f763 100644
--- a/doc/src/sgml/earthdistance.sgml
+++ b/doc/src/sgml/earthdistance.sgml
@@ -10,9 +10,8 @@
<para>
The <filename>earthdistance</> module provides two different approaches to
calculating great circle distances on the surface of the Earth. The one
- described first depends on the <filename>cube</> module (which
- <emphasis>must</> be installed before <filename>earthdistance</> can be
- installed). The second one is based on the built-in <type>point</> data type,
+ described first depends on the <filename>cube</filename> module.
+ The second one is based on the built-in <type>point</type> data type,
using longitude and latitude for the coordinates.
</para>
@@ -23,6 +22,28 @@
project.)
</para>
+ <para>
+ The <filename>cube</filename> module must be installed
+ before <filename>earthdistance</filename> can be installed
+ (although you can use the <literal>CASCADE</literal> option
+ of <command>CREATE EXTENSION</command> to install both in one command).
+ </para>
+
+ <caution>
+ <para>
+ It is strongly recommended that <filename>earthdistance</filename>
+ and <filename>cube</filename> be installed in the same schema, and that
+ that schema be one for which CREATE privilege has not been and will not
+ be granted to any untrusted users.
+ Otherwise there are installation-time security hazards
+ if <filename>earthdistance</filename>'s schema contains objects defined
+ by a hostile user.
+ Furthermore, when using <filename>earthdistance</filename>'s functions
+ after installation, the entire search path should contain only trusted
+ schemas.
+ </para>
+ </caution>
+
<sect2>
<title>Cube-based Earth Distances</title>
diff --git a/doc/src/sgml/extend.sgml b/doc/src/sgml/extend.sgml
index 8c68d595e5..501f9e1391 100644
--- a/doc/src/sgml/extend.sgml
+++ b/doc/src/sgml/extend.sgml
@@ -355,7 +355,7 @@
<para>
The extension script may set privileges on objects that are part of the
- extension via <command>GRANT</command> and <command>REVOKE</command>
+ extension, using <command>GRANT</command> and <command>REVOKE</command>
statements. The final set of privileges for each object (if any are set)
will be stored in the
<link linkend="catalog-pg-init-privs"><structname>pg_init_privs</structname></link>
@@ -412,32 +412,6 @@
dropping the whole extension.
</para>
- <sect2 id="extend-extensions-style">
- <title>Defining Extension Objects</title>
-
- <!-- XXX It's not enough to use qualified names, because one might write a
- qualified name to an object that itself uses unqualified names. Many
- information_schema functions have that defect, for example. However,
- that's a defect in the referenced object, and relatively few queries
- will be affected. Also, we direct applications to secure search_path
- when connecting to an untrusted database; if applications do that,
- they are immune to known attacks even if some extension refers to a
- defective object. Therefore, guide extension authors as though core
- PostgreSQL contained no such defect. -->
- <para>
- Widely-distributed extensions should assume little about the database
- they occupy. In particular, unless you issued <literal>SET search_path =
- pg_temp</literal>, assume each unqualified name could resolve to an
- object that a malicious user has defined. Beware of constructs that
- depend on <varname>search_path</varname> implicitly: <token>IN</token>
- and <literal>CASE <replaceable>expression</replaceable> WHEN</literal>
- always select an operator using the search path. In their place, use
- <literal>OPERATOR(<replaceable>schema</replaceable>.=) ANY</literal>
- and <literal>CASE WHEN <replaceable>expression</replaceable></literal>.
- </para>
-
- </sect2>
-
<sect2>
<title>Extension Files</title>
@@ -699,7 +673,7 @@
schema; that is, <command>CREATE EXTENSION</> does the equivalent of
this:
<programlisting>
-SET LOCAL search_path TO @extschema@;
+SET LOCAL search_path TO @extschema@, pg_temp;
</programlisting>
This allows the objects created by the script file to go into the target
schema. The script file can change <varname>search_path</> if it wishes,
@@ -719,9 +693,15 @@ SET LOCAL search_path TO @extschema@;
<para>
If any prerequisite extensions are listed in <varname>requires</varname>
- in the control file, their target schemas are appended to the initial
- setting of <varname>search_path</>. This allows their objects to be
- visible to the new extension's script file.
+ in the control file, their target schemas are added to the initial
+ setting of <varname>search_path</varname>, following the new
+ extension's target schema. This allows their objects to be visible to
+ the new extension's script file.
+ </para>
+
+ <para>
+ For security, <literal>pg_temp</literal> is automatically appended to
+ the end of <varname>search_path</varname> in all cases.
</para>
<para>
@@ -975,6 +955,143 @@ SELECT * FROM pg_extension_update_paths('<replaceable>extension_name</>');
</para>
</sect2>
+ <sect2 id="extend-extensions-security">
+ <title>Security Considerations for Extensions</title>
+
+ <para>
+ Widely-distributed extensions should assume little about the database
+ they occupy. Therefore, it's appropriate to write functions provided
+ by an extension in a secure style that cannot be compromised by
+ search-path-based attacks.
+ </para>
+
+ <para>
+ An extension that has the <varname>superuser</varname> property set to
+ true must also consider security hazards for the actions taken within
+ its installation and update scripts. It is not terribly difficult for
+ a malicious user to create trojan-horse objects that will compromise
+ later execution of a carelessly-written extension script, allowing that
+ user to acquire superuser privileges.
+ </para>
+
+ <para>
+ Advice about writing functions securely is provided in
+ <xref linkend="extend-extensions-security-funcs"> below, and advice
+ about writing installation scripts securely is provided in
+ <xref linkend="extend-extensions-security-scripts">.
+ </para>
+
+ <sect3 id="extend-extensions-security-funcs">
+ <title>Security Considerations for Extension Functions</title>
+
+ <para>
+ SQL-language and PL-language functions provided by extensions are at
+ risk of search-path-based attacks when they are executed, since
+ parsing of these functions occurs at execution time not creation time.
+ </para>
+
+ <para>
+ The <link linkend="sql-createfunction-security"><command>CREATE
+ FUNCTION</command></link> reference page contains advice about
+ writing <literal>SECURITY DEFINER</literal> functions safely. It's
+ good practice to apply those techniques for any function provided by
+ an extension, since the function might be called by a high-privilege
+ user.
+ </para>
+
+ <!-- XXX It's not enough to use qualified names, because one might write a
+ qualified name to an object that itself uses unqualified names. Many
+ information_schema functions have that defect, for example. However,
+ that's a defect in the referenced object, and relatively few queries
+ will be affected. Also, we direct applications to secure search_path
+ when connecting to an untrusted database; if applications do that,
+ they are immune to known attacks even if some extension refers to a
+ defective object. Therefore, guide extension authors as though core
+ PostgreSQL contained no such defect. -->
+ <para>
+ If you cannot set the <varname>search_path</varname> to contain only
+ secure schemas, assume that each unqualified name could resolve to an
+ object that a malicious user has defined. Beware of constructs that
+ depend on <varname>search_path</varname> implicitly; for
+ example, <token>IN</token>
+ and <literal>CASE <replaceable>expression</replaceable> WHEN</literal>
+ always select an operator using the search path. In their place, use
+ <literal>OPERATOR(<replaceable>schema</replaceable>.=) ANY</literal>
+ and <literal>CASE WHEN <replaceable>expression</replaceable></literal>.
+ </para>
+
+ <para>
+ A general-purpose extension usually should not assume that it's been
+ installed into a secure schema, which means that even schema-qualified
+ references to its own objects are not entirely risk-free. For
+ example, if the extension has defined a
+ function <literal>myschema.myfunc(bigint)</literal> then a call such
+ as <literal>myschema.myfunc(42)</literal> could be captured by a
+ hostile function <literal>myschema.myfunc(integer)</literal>. Be
+ careful that the data types of function and operator parameters exactly
+ match the declared argument types, using explicit casts where necessary.
+ </para>
+ </sect3>
+
+ <sect3 id="extend-extensions-security-scripts">
+ <title>Security Considerations for Extension Scripts</title>
+
+ <para>
+ An extension installation or update script should be written to guard
+ against search-path-based attacks occurring when the script executes.
+ If an object reference in the script can be made to resolve to some
+ other object than the script author intended, then a compromise might
+ occur immediately, or later when the mis-defined extension object is
+ used.
+ </para>
+
+ <para>
+ DDL commands such as <command>CREATE FUNCTION</command>
+ and <command>CREATE OPERATOR CLASS</command> are generally secure,
+ but beware of any command having a general-purpose expression as a
+ component. For example, <command>CREATE VIEW</command> needs to be
+ vetted, as does a <literal>DEFAULT</literal> expression
+ in <command>CREATE FUNCTION</command>.
+ </para>
+
+ <para>
+ Sometimes an extension script might need to execute general-purpose
+ SQL, for example to make catalog adjustments that aren't possible via
+ DDL. Be careful to execute such commands with a
+ secure <varname>search_path</varname>; do <emphasis>not</emphasis>
+ trust the path provided by <command>CREATE/ALTER EXTENSION</command>
+ to be secure. Best practice is to temporarily
+ set <varname>search_path</varname> to <literal>'pg_catalog,
+ pg_temp'</literal> and insert references to the extension's
+ installation schema explicitly where needed. (This practice might
+ also be helpful for creating views.) Examples can be found in
+ the <filename>contrib</filename> modules in
+ the <productname>PostgreSQL</productname> source code distribution.
+ </para>
+
+ <para>
+ Cross-extension references are extremely difficult to make fully
+ secure, partially because of uncertainty about which schema the other
+ extension is in. The hazards are reduced if both extensions are
+ installed in the same schema, because then a hostile object cannot be
+ placed ahead of the referenced extension in the installation-time
+ <varname>search_path</varname>. However, no mechanism currently exists
+ to require that.
+ </para>
+
+ <para>
+ Do <emphasis>not</emphasis> use <command>CREATE OR REPLACE
+ FUNCTION</command>, except in an update script that must change the
+ definition of a function that is known to be an extension member
+ already. (Likewise for other <literal>OR REPLACE</literal> options.)
+ Using <literal>OR REPLACE</literal> unnecessarily not only has a risk
+ of accidentally overwriting someone else's function, but it creates a
+ security hazard since the overwritten function would still be owned by
+ its original owner, who could modify it.
+ </para>
+ </sect3>
+ </sect2>
+
<sect2 id="extend-extensions-example">
<title>Extension Example</title>
@@ -994,18 +1111,18 @@ SELECT * FROM pg_extension_update_paths('<replaceable>extension_name</>');
CREATE TYPE pair AS ( k text, v text );
-CREATE OR REPLACE FUNCTION pair(text, text)
+CREATE FUNCTION pair(text, text)
RETURNS pair LANGUAGE SQL AS 'SELECT ROW($1, $2)::@extschema@.pair;';
CREATE OPERATOR ~> (LEFTARG = text, RIGHTARG = text, PROCEDURE = pair);
-- "SET search_path" is easy to get right, but qualified names perform better.
-CREATE OR REPLACE FUNCTION lower(pair)
+CREATE FUNCTION lower(pair)
RETURNS pair LANGUAGE SQL
AS 'SELECT ROW(lower($1.k), lower($1.v))::@extschema@.pair;'
SET search_path = pg_temp;
-CREATE OR REPLACE FUNCTION pair_concat(pair, pair)
+CREATE FUNCTION pair_concat(pair, pair)
RETURNS pair LANGUAGE SQL
AS 'SELECT ROW($1.k OPERATOR(pg_catalog.||) $2.k,
$1.v OPERATOR(pg_catalog.||) $2.v)::@extschema@.pair;';
@@ -1020,6 +1137,7 @@ AS 'SELECT ROW($1.k OPERATOR(pg_catalog.||) $2.k,
# pair extension
comment = 'A key/value pair data type'
default_version = '1.0'
+# cannot be relocatable because of use of @extschema@
relocatable = false
</programlisting>
</para>
diff --git a/doc/src/sgml/hstore.sgml b/doc/src/sgml/hstore.sgml
index db5d4409a6..fee2812dd0 100644
--- a/doc/src/sgml/hstore.sgml
+++ b/doc/src/sgml/hstore.sgml
@@ -633,6 +633,15 @@ ALTER TABLE tablename ALTER hstorecol TYPE hstore USING hstorecol || '';
convention). If you use them, <type>hstore</type> values are mapped to
Python dictionaries.
</para>
+
+ <caution>
+ <para>
+ It is strongly recommended that the transform extensions be installed in
+ the same schema as <filename>hstore</filename>. Otherwise there are
+ installation-time security hazards if a transform extension's schema
+ contains objects defined by a hostile user.
+ </para>
+ </caution>
</sect2>
<sect2>
diff --git a/doc/src/sgml/ltree.sgml b/doc/src/sgml/ltree.sgml
index b399391da1..70ad7d3421 100644
--- a/doc/src/sgml/ltree.sgml
+++ b/doc/src/sgml/ltree.sgml
@@ -674,6 +674,15 @@ ltreetest=&gt; SELECT ins_label(path,2,'Space') FROM test WHERE path &lt;@ 'Top.
creating a function, <type>ltree</type> values are mapped to Python lists.
(The reverse is currently not supported, however.)
</para>
+
+ <caution>
+ <para>
+ It is strongly recommended that the transform extensions be installed in
+ the same schema as <filename>ltree</filename>. Otherwise there are
+ installation-time security hazards if a transform extension's schema
+ contains objects defined by a hostile user.
+ </para>
+ </caution>
</sect2>
<sect2>
diff --git a/doc/src/sgml/ref/create_extension.sgml b/doc/src/sgml/ref/create_extension.sgml
index 14e910115a..8016c78911 100644
--- a/doc/src/sgml/ref/create_extension.sgml
+++ b/doc/src/sgml/ref/create_extension.sgml
@@ -193,6 +193,33 @@ CREATE EXTENSION [ IF NOT EXISTS ] <replaceable class="parameter">extension_name
system views.
</para>
+ <caution>
+ <para>
+ Installing an extension as superuser requires trusting that the
+ extension's author wrote the extension installation script in a secure
+ fashion. It is not terribly difficult for a malicious user to create
+ trojan-horse objects that will compromise later execution of a
+ carelessly-written extension script, allowing that user to acquire
+ superuser privileges. However, trojan-horse objects are only hazardous
+ if they are in the <varname>search_path</varname> during script
+ execution, meaning that they are in the extension's installation target
+ schema or in the schema of some extension it depends on. Therefore, a
+ good rule of thumb when dealing with extensions whose scripts have not
+ been carefully vetted is to install them only into schemas for which
+ CREATE privilege has not been and will not be granted to any untrusted
+ users. Likewise for any extensions they depend on.
+ </para>
+
+ <para>
+ The extensions supplied with <productname>PostgreSQL</productname> are
+ believed to be secure against installation-time attacks of this sort,
+ except for a few that depend on other extensions. As stated in the
+ documentation for those extensions, they should be installed into secure
+ schemas, or installed into the same schemas as the extensions they
+ depend on, or both.
+ </para>
+ </caution>
+
<para>
For information about writing new extensions, see
<xref linkend="extend-extensions">.
@@ -204,8 +231,13 @@ CREATE EXTENSION [ IF NOT EXISTS ] <replaceable class="parameter">extension_name
<para>
Install the <link linkend="hstore">hstore</link> extension into the
- current database:
+ current database, placing its objects in schema <literal>addons</literal>:
+<programlisting>
+CREATE EXTENSION hstore SCHEMA addons;
+</programlisting>
+ Another way to accomplish the same thing:
<programlisting>
+SET search_path = addons;
CREATE EXTENSION hstore;
</programlisting>
</para>
diff --git a/doc/src/sgml/release-10.sgml b/doc/src/sgml/release-10.sgml
index 720c1a1529..b71d7f679e 100644
--- a/doc/src/sgml/release-10.sgml
+++ b/doc/src/sgml/release-10.sgml
@@ -10544,7 +10544,7 @@ Branch: REL9_3_STABLE [41ee473a4] 2018-02-26 07:39:48 -0800
one's search path. Relevant documentation appears in
<xref linkend="ddl-schemas-patterns"> (for database administrators and users),
<xref linkend="libpq-connect"> (for application authors),
- <xref linkend="extend-extensions-style"> (for extension authors), and
+ <xref linkend="extend-extensions-security"> (for extension authors), and
<xref linkend="sql-createfunction"> (for authors
of <literal>SECURITY DEFINER</literal> functions).
(CVE-2018-1058)
diff --git a/src/backend/commands/extension.c b/src/backend/commands/extension.c
index a52b6861b4..8e23c70fb3 100644
--- a/src/backend/commands/extension.c
+++ b/src/backend/commands/extension.c
@@ -838,9 +838,21 @@ execute_extension_script(Oid extensionOid, ExtensionControlFile *control,
GUC_ACTION_SAVE, true, 0, false);
/*
- * Set up the search path to contain the target schema, then the schemas
- * of any prerequisite extensions, and nothing else. In particular this
- * makes the target schema be the default creation target namespace.
+ * Similarly disable check_function_bodies, to ensure that SQL functions
+ * won't be parsed during creation.
+ */
+ if (check_function_bodies)
+ (void) set_config_option("check_function_bodies", "off",
+ PGC_USERSET, PGC_S_SESSION,
+ GUC_ACTION_SAVE, true, 0, false);
+
+ /*
+ * Set up the search path to have the target schema first, making it be
+ * the default creation target namespace. Then add the schemas of any
+ * prerequisite extensions, unless they are in pg_catalog which would be
+ * searched anyway. (Listing pg_catalog explicitly in a non-first
+ * position would be bad for security.) Finally add pg_temp to ensure
+ * that temp objects can't take precedence over others.
*
* Note: it might look tempting to use PushOverrideSearchPath for this,
* but we cannot do that. We have to actually set the search_path GUC in
@@ -854,9 +866,10 @@ execute_extension_script(Oid extensionOid, ExtensionControlFile *control,
Oid reqschema = lfirst_oid(lc);
char *reqname = get_namespace_name(reqschema);
- if (reqname)
+ if (reqname && strcmp(reqname, "pg_catalog") != 0)
appendStringInfo(&pathbuf, ", %s", quote_identifier(reqname));
}
+ appendStringInfoString(&pathbuf, ", pg_temp");
(void) set_config_option("search_path", pathbuf.data,
PGC_USERSET, PGC_S_SESSION,
diff --git a/src/backend/commands/operatorcmds.c b/src/backend/commands/operatorcmds.c
index 6674b41eec..b637cd4e55 100644
--- a/src/backend/commands/operatorcmds.c
+++ b/src/backend/commands/operatorcmds.c
@@ -297,6 +297,7 @@ ValidateJoinEstimator(List *joinName)
{
Oid typeId[5];
Oid joinOid;
+ Oid joinOid2;
AclResult aclresult;
typeId[0] = INTERNALOID; /* PlannerInfo */
@@ -307,15 +308,26 @@ ValidateJoinEstimator(List *joinName)
/*
* As of Postgres 8.4, the preferred signature for join estimators has 5
- * arguments, but we still allow the old 4-argument form. Try the
- * preferred form first.
+ * arguments, but we still allow the old 4-argument form. Whine about
+ * ambiguity if both forms exist.
*/
joinOid = LookupFuncName(joinName, 5, typeId, true);
- if (!OidIsValid(joinOid))
- joinOid = LookupFuncName(joinName, 4, typeId, true);
- /* If not found, reference the 5-argument signature in error msg */
- if (!OidIsValid(joinOid))
- joinOid = LookupFuncName(joinName, 5, typeId, false);
+ joinOid2 = LookupFuncName(joinName, 4, typeId, true);
+ if (OidIsValid(joinOid))
+ {
+ if (OidIsValid(joinOid2))
+ ereport(ERROR,
+ (errcode(ERRCODE_AMBIGUOUS_FUNCTION),
+ errmsg("join estimator function %s has multiple matches",
+ NameListToString(joinName))));
+ }
+ else
+ {
+ joinOid = joinOid2;
+ /* If not found, reference the 5-argument signature in error msg */
+ if (!OidIsValid(joinOid))
+ joinOid = LookupFuncName(joinName, 5, typeId, false);
+ }
/* estimators must return float8 */
if (get_func_rettype(joinOid) != FLOAT8OID)
diff --git a/src/backend/commands/typecmds.c b/src/backend/commands/typecmds.c
index a6231b8f25..d938d84962 100644
--- a/src/backend/commands/typecmds.c
+++ b/src/backend/commands/typecmds.c
@@ -1659,7 +1659,11 @@ static Oid
findTypeInputFunction(List *procname, Oid typeOid)
{
Oid argList[3];
+ int nmatches = 0;
Oid procOid;
+ Oid procOid2;
+ Oid procOid3;
+ Oid procOid4;
/*
* Input functions can take a single argument of type CSTRING, or three
@@ -1667,32 +1671,45 @@ findTypeInputFunction(List *procname, Oid typeOid)
*
* For backwards compatibility we allow OPAQUE in place of CSTRING; if we
* see this, we issue a warning and fix up the pg_proc entry.
+ *
+ * Whine about ambiguity if multiple forms exist.
*/
argList[0] = CSTRINGOID;
-
- procOid = LookupFuncName(procname, 1, argList, true);
- if (OidIsValid(procOid))
- return procOid;
-
argList[1] = OIDOID;
argList[2] = INT4OID;
- procOid = LookupFuncName(procname, 3, argList, true);
+ procOid = LookupFuncName(procname, 1, argList, true);
if (OidIsValid(procOid))
- return procOid;
+ nmatches++;
+ procOid2 = LookupFuncName(procname, 3, argList, true);
+ if (OidIsValid(procOid2))
+ nmatches++;
- /* No luck, try it with OPAQUE */
argList[0] = OPAQUEOID;
- procOid = LookupFuncName(procname, 1, argList, true);
+ procOid3 = LookupFuncName(procname, 1, argList, true);
+ if (OidIsValid(procOid3))
+ nmatches++;
+ procOid4 = LookupFuncName(procname, 3, argList, true);
+ if (OidIsValid(procOid4))
+ nmatches++;
- if (!OidIsValid(procOid))
- {
- argList[1] = OIDOID;
- argList[2] = INT4OID;
+ if (nmatches > 1)
+ ereport(ERROR,
+ (errcode(ERRCODE_AMBIGUOUS_FUNCTION),
+ errmsg("type input function %s has multiple matches",
+ NameListToString(procname))));
- procOid = LookupFuncName(procname, 3, argList, true);
- }
+ if (OidIsValid(procOid))
+ return procOid;
+ if (OidIsValid(procOid2))
+ return procOid2;
+
+ /* Cases with OPAQUE need adjustment */
+ if (OidIsValid(procOid3))
+ procOid = procOid3;
+ else
+ procOid = procOid4;
if (OidIsValid(procOid))
{
@@ -1778,24 +1795,32 @@ findTypeReceiveFunction(List *procname, Oid typeOid)
{
Oid argList[3];
Oid procOid;
+ Oid procOid2;
/*
* Receive functions can take a single argument of type INTERNAL, or three
- * arguments (internal, typioparam OID, typmod).
+ * arguments (internal, typioparam OID, typmod). Whine about ambiguity if
+ * both forms exist.
*/
argList[0] = INTERNALOID;
-
- procOid = LookupFuncName(procname, 1, argList, true);
- if (OidIsValid(procOid))
- return procOid;
-
argList[1] = OIDOID;
argList[2] = INT4OID;
- procOid = LookupFuncName(procname, 3, argList, true);
+ procOid = LookupFuncName(procname, 1, argList, true);
+ procOid2 = LookupFuncName(procname, 3, argList, true);
if (OidIsValid(procOid))
+ {
+ if (OidIsValid(procOid2))
+ ereport(ERROR,
+ (errcode(ERRCODE_AMBIGUOUS_FUNCTION),
+ errmsg("type receive function %s has multiple matches",
+ NameListToString(procname))));
return procOid;
+ }
+ else if (OidIsValid(procOid2))
+ return procOid2;
+ /* If not found, reference the 1-argument signature in error msg */
ereport(ERROR,
(errcode(ERRCODE_UNDEFINED_FUNCTION),
errmsg("function %s does not exist",