-- 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
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
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
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
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
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
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
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
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
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
);
-- somewhat arbitrarily, we assume no citext indexes have more than 8 columns
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
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
-- 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
IF NOT FOUND
THEN
+ PERFORM pg_catalog.set_config('search_path', old_path, true);
CREATE FUNCTION hstore_to_json(hstore)
RETURNS json
END IF;
+PERFORM pg_catalog.set_config('search_path', old_path, true);
END;
$$;
-- 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
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
+$$;
-- 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:
-- Avert your eyes while we hack the pg_amproc entries to make them link to
-- the new forms ...
+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_amproc
SET amproc = 'pg_catalog.gin_extract_tsvector(pg_catalog.tsvector,internal,internal)'::pg_catalog.regprocedure
WHERE amprocfamily =
(SELECT oid FROM pg_catalog.pg_opfamily WHERE opfname = 'gin_tsvector_ops' AND
opfnamespace = (SELECT oid FROM pg_catalog.pg_namespace
- WHERE nspname = '@extschema@'))
+ WHERE nspname = my_schema_unquoted))
AND amproclefttype = 'pg_catalog.tsvector'::pg_catalog.regtype
AND amprocrighttype = 'pg_catalog.tsvector'::pg_catalog.regtype
AND amprocnum = 2
WHERE amprocfamily =
(SELECT oid FROM pg_catalog.pg_opfamily WHERE opfname = 'gin_tsvector_ops' AND
opfnamespace = (SELECT oid FROM pg_catalog.pg_namespace
- WHERE nspname = '@extschema@'))
+ WHERE nspname = my_schema_unquoted))
AND amproclefttype = 'pg_catalog.tsvector'::pg_catalog.regtype
AND amprocrighttype = 'pg_catalog.tsvector'::pg_catalog.regtype
AND amprocnum = 3
WHERE amprocfamily =
(SELECT oid FROM pg_catalog.pg_opfamily WHERE opfname = 'gin_tsvector_ops' AND
opfnamespace = (SELECT oid FROM pg_catalog.pg_namespace
- WHERE nspname = '@extschema@'))
+ WHERE nspname = my_schema_unquoted))
AND amproclefttype = 'pg_catalog.tsvector'::pg_catalog.regtype
AND amprocrighttype = 'pg_catalog.tsvector'::pg_catalog.regtype
AND amprocnum = 4
AND amproc = 'pg_catalog.gin_tsquery_consistent(internal,smallint,pg_catalog.tsquery,integer,internal,internal)'::pg_catalog.regprocedure;
+
+PERFORM pg_catalog.set_config('search_path', old_path, true);
+END
+$$;
<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>
project.)
</para>
+ <para>
+ The <filename>cube</filename> module must be installed
+ before <filename>earthdistance</filename> can be installed.
+ </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>
schema(s) its member objects are within.
</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>
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,
<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>
</para>
</sect2>
- <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>
<para>
CREATE TYPE pair AS ( k text, v text );
-CREATE OR REPLACE FUNCTION pair(text, text)
+CREATE FUNCTION pair(text, text)
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
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,
# 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>
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>
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>
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">.
<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>
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)
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
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,
*/
if (joinName)
{
+ Oid joinOid2;
+
typeId[0] = INTERNALOID; /* PlannerInfo */
typeId[1] = OIDOID; /* operator OID */
typeId[2] = INTERNALOID; /* args list */
/*
* 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.
+ * 5 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)
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
*
* 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))
{
{
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",