Revoke PUBLIC CREATE from public schema, now owned by pg_database_owner.

This switches the default ACL to what the documentation has recommended
since CVE-2018-1058.  Upgrades will carry forward any old ownership and
ACL.  Sites that declined the 2018 recommendation should take a fresh
look.  Recipes for commissioning a new database cluster from scratch may
need to create a schema, grant more privileges, etc.  Out-of-tree test
suites may require such updates.

Reviewed by Peter Eisentraut.

Discussion: https://postgr.es/m/20201031163518.GB4039133@rfd.leadboat.com
This commit is contained in:
Noah Misch 2021-09-09 23:38:09 -07:00
parent cba79a1632
commit b073c3ccd0
13 changed files with 86 additions and 64 deletions

View File

@ -9428,7 +9428,7 @@ $d$;
-- But creation of user mappings for non-superusers should fail -- But creation of user mappings for non-superusers should fail
CREATE USER MAPPING FOR public SERVER loopback_nopw; CREATE USER MAPPING FOR public SERVER loopback_nopw;
CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw; CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
CREATE FOREIGN TABLE ft1_nopw ( CREATE FOREIGN TABLE pg_temp.ft1_nopw (
c1 int NOT NULL, c1 int NOT NULL,
c2 int NOT NULL, c2 int NOT NULL,
c3 text, c3 text,

View File

@ -2797,7 +2797,7 @@ $d$;
CREATE USER MAPPING FOR public SERVER loopback_nopw; CREATE USER MAPPING FOR public SERVER loopback_nopw;
CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw; CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
CREATE FOREIGN TABLE ft1_nopw ( CREATE FOREIGN TABLE pg_temp.ft1_nopw (
c1 int NOT NULL, c1 int NOT NULL,
c2 int NOT NULL, c2 int NOT NULL,
c3 text, c3 text,

View File

@ -3001,20 +3001,18 @@ SELECT 3 OPERATOR(pg_catalog.+) 4;
<para> <para>
By default, users cannot access any objects in schemas they do not By default, users cannot access any objects in schemas they do not
own. To allow that, the owner of the schema must grant the own. To allow that, the owner of the schema must grant the
<literal>USAGE</literal> privilege on the schema. To allow users <literal>USAGE</literal> privilege on the schema. By default, everyone
to make use of the objects in the schema, additional privileges has that privilege on the schema <literal>public</literal>. To allow
might need to be granted, as appropriate for the object. users to make use of the objects in a schema, additional privileges might
need to be granted, as appropriate for the object.
</para> </para>
<para> <para>
A user can also be allowed to create objects in someone else's A user can also be allowed to create objects in someone else's schema. To
schema. To allow that, the <literal>CREATE</literal> privilege on allow that, the <literal>CREATE</literal> privilege on the schema needs to
the schema needs to be granted. Note that by default, everyone be granted. In databases upgraded from
has <literal>CREATE</literal> and <literal>USAGE</literal> privileges on <productname>PostgreSQL</productname> 14 or earlier, everyone has that
the schema privilege on the schema <literal>public</literal>.
<literal>public</literal>. This allows all users that are able to
connect to a given database to create objects in its
<literal>public</literal> schema.
Some <link linkend="ddl-schemas-patterns">usage patterns</link> call for Some <link linkend="ddl-schemas-patterns">usage patterns</link> call for
revoking that privilege: revoking that privilege:
<programlisting> <programlisting>
@ -3087,20 +3085,25 @@ REVOKE CREATE ON SCHEMA public FROM PUBLIC;
database owner attack. --> database owner attack. -->
<para> <para>
Constrain ordinary users to user-private schemas. To implement this, Constrain ordinary users to user-private schemas. To implement this,
issue <literal>REVOKE CREATE ON SCHEMA public FROM PUBLIC</literal>, first issue <literal>REVOKE CREATE ON SCHEMA public FROM
and create a schema for each user with the same name as that user. PUBLIC</literal>. Then, for every user needing to create non-temporary
Recall that the default search path starts objects, create a schema with the same name as that user. Recall that
with <literal>$user</literal>, which resolves to the user name. the default search path starts with <literal>$user</literal>, which
Therefore, if each user has a separate schema, they access their own resolves to the user name. Therefore, if each user has a separate
schemas by default. After adopting this pattern in a database where schema, they access their own schemas by default. After adopting this
untrusted users had already logged in, consider auditing the public pattern in a database where untrusted users had already logged in,
schema for objects named like objects in consider auditing the public schema for objects named like objects in
schema <literal>pg_catalog</literal>. This pattern is a secure schema schema <literal>pg_catalog</literal>. This pattern is a secure schema
usage pattern unless an untrusted user is the database owner or holds usage pattern unless an untrusted user is the database owner or holds
the <literal>CREATEROLE</literal> privilege, in which case no secure the <literal>CREATEROLE</literal> privilege, in which case no secure
schema usage pattern exists. schema usage pattern exists.
</para> </para>
<para> <para>
If the database originated in an upgrade
from <productname>PostgreSQL</productname> 14 or earlier,
the <literal>REVOKE</literal> is essential. Otherwise, the default
configuration follows this pattern; ordinary users can create only
temporary objects until a privileged user furnishes a schema.
</para> </para>
</listitem> </listitem>
@ -3109,10 +3112,10 @@ REVOKE CREATE ON SCHEMA public FROM PUBLIC;
Remove the public schema from the default search path, by modifying Remove the public schema from the default search path, by modifying
<link linkend="config-setting-configuration-file"><filename>postgresql.conf</filename></link> <link linkend="config-setting-configuration-file"><filename>postgresql.conf</filename></link>
or by issuing <literal>ALTER ROLE ALL SET search_path = or by issuing <literal>ALTER ROLE ALL SET search_path =
"$user"</literal>. Everyone retains the ability to create objects in "$user"</literal>. Then, grant privileges to create in the public
the public schema, but only qualified names will choose those objects. schema. Only qualified names will choose public schema objects. While
While qualified table references are fine, calls to functions in the qualified table references are fine, calls to functions in the public
public schema <link linkend="typeconv-func">will be unsafe or schema <link linkend="typeconv-func">will be unsafe or
unreliable</link>. If you create functions or extensions in the public unreliable</link>. If you create functions or extensions in the public
schema, use the first pattern instead. Otherwise, like the first schema, use the first pattern instead. Otherwise, like the first
pattern, this is secure unless an untrusted user is the database owner pattern, this is secure unless an untrusted user is the database owner
@ -3122,11 +3125,14 @@ REVOKE CREATE ON SCHEMA public FROM PUBLIC;
<listitem> <listitem>
<para> <para>
Keep the default. All users access the public schema implicitly. This Keep the default search path, and grant privileges to create in the
public schema. All users access the public schema implicitly. This
simulates the situation where schemas are not available at all, giving simulates the situation where schemas are not available at all, giving
a smooth transition from the non-schema-aware world. However, this is a smooth transition from the non-schema-aware world. However, this is
never a secure pattern. It is acceptable only when the database has a never a secure pattern. It is acceptable only when the database has a
single user or a few mutually-trusting users. single user or a few mutually-trusting users. In databases upgraded
from <productname>PostgreSQL</productname> 14 or earlier, this is the
default.
</para> </para>
</listitem> </listitem>
</itemizedlist> </itemizedlist>

View File

@ -597,13 +597,14 @@ DROP ROLE doomed_role;
<para> <para>
The <literal>pg_database_owner</literal> role has one implicit, The <literal>pg_database_owner</literal> role has one implicit,
situation-dependent member, namely the owner of the current database. The situation-dependent member, namely the owner of the current database. Like
role conveys no rights at first. Like any role, it can own objects or any role, it can own objects or receive grants of access privileges.
receive grants of access privileges. Consequently, once Consequently, once <literal>pg_database_owner</literal> has rights within a
<literal>pg_database_owner</literal> has rights within a template database, template database, each owner of a database instantiated from that template
each owner of a database instantiated from that template will exercise those will exercise those rights. <literal>pg_database_owner</literal> cannot be
rights. <literal>pg_database_owner</literal> cannot be a member of any a member of any role, and it cannot have non-implicit members. Initially,
role, and it cannot have non-implicit members. this role owns the <literal>public</literal> schema, so each database owner
governs local use of the schema.
</para> </para>
<para> <para>
@ -652,8 +653,8 @@ GRANT pg_signal_backend TO admin_user;
horse</quote> others with relative ease. The strongest protection is tight horse</quote> others with relative ease. The strongest protection is tight
control over who can define objects. Where that is infeasible, write control over who can define objects. Where that is infeasible, write
queries referring only to objects having trusted owners. Remove queries referring only to objects having trusted owners. Remove
from <varname>search_path</varname> the public schema and any other schemas from <varname>search_path</varname> any schemas that permit untrusted users
that permit untrusted users to create objects. to create objects.
</para> </para>
<para> <para>

View File

@ -1633,8 +1633,7 @@ setup_privileges(FILE *cmdfd)
CppAsString2(RELKIND_VIEW) ", " CppAsString2(RELKIND_MATVIEW) ", " CppAsString2(RELKIND_VIEW) ", " CppAsString2(RELKIND_MATVIEW) ", "
CppAsString2(RELKIND_SEQUENCE) ")" CppAsString2(RELKIND_SEQUENCE) ")"
" AND relacl IS NULL;\n\n", " AND relacl IS NULL;\n\n",
"GRANT USAGE ON SCHEMA pg_catalog TO PUBLIC;\n\n", "GRANT USAGE ON SCHEMA pg_catalog, public TO PUBLIC;\n\n",
"GRANT CREATE, USAGE ON SCHEMA public TO PUBLIC;\n\n",
"REVOKE ALL ON pg_largeobject FROM PUBLIC;\n\n", "REVOKE ALL ON pg_largeobject FROM PUBLIC;\n\n",
"INSERT INTO pg_init_privs " "INSERT INTO pg_init_privs "
" (objoid, classoid, objsubid, initprivs, privtype)" " (objoid, classoid, objsubid, initprivs, privtype)"

View File

@ -1623,11 +1623,12 @@ selectDumpableNamespace(NamespaceInfo *nsinfo, Archive *fout)
* no-mans-land between being a system object and a user object. * no-mans-land between being a system object and a user object.
* CREATE SCHEMA would fail, so its DUMP_COMPONENT_DEFINITION is just * CREATE SCHEMA would fail, so its DUMP_COMPONENT_DEFINITION is just
* a comment and an indication of ownership. If the owner is the * a comment and an indication of ownership. If the owner is the
* default, that DUMP_COMPONENT_DEFINITION is superfluous. * default, omit that superfluous DUMP_COMPONENT_DEFINITION. Before
* v15, the default owner was BOOTSTRAP_SUPERUSERID.
*/ */
nsinfo->create = false; nsinfo->create = false;
nsinfo->dobj.dump = DUMP_COMPONENT_ALL; nsinfo->dobj.dump = DUMP_COMPONENT_ALL;
if (nsinfo->nspowner == BOOTSTRAP_SUPERUSERID) if (nsinfo->nspowner == ROLE_PG_DATABASE_OWNER)
nsinfo->dobj.dump &= ~DUMP_COMPONENT_DEFINITION; nsinfo->dobj.dump &= ~DUMP_COMPONENT_DEFINITION;
nsinfo->dobj.dump_contains = DUMP_COMPONENT_ALL; nsinfo->dobj.dump_contains = DUMP_COMPONENT_ALL;
} }
@ -4850,21 +4851,26 @@ getNamespaces(Archive *fout, int *numNamespaces)
PQExpBuffer init_racl_subquery = createPQExpBuffer(); PQExpBuffer init_racl_subquery = createPQExpBuffer();
/* /*
* Bypass pg_init_privs.initprivs for the public schema. Dropping and * Bypass pg_init_privs.initprivs for the public schema, for several
* recreating the schema detaches it from its pg_init_privs row, but * reasons. First, dropping and recreating the schema detaches it
* an empty destination database starts with this ACL nonetheless. * from its pg_init_privs row, but an empty destination database
* Also, we support dump/reload of public schema ownership changes. * starts with this ACL nonetheless. Second, we support dump/reload
* ALTER SCHEMA OWNER filters nspacl through aclnewowner(), but * of public schema ownership changes. ALTER SCHEMA OWNER filters
* initprivs continues to reflect the initial owner (the bootstrap * nspacl through aclnewowner(), but initprivs continues to reflect
* superuser). Hence, synthesize the value that nspacl will have * the initial owner. Hence, synthesize the value that nspacl will
* after the restore's ALTER SCHEMA OWNER. * have after the restore's ALTER SCHEMA OWNER. Third, this makes the
* destination database match the source's ACL, even if the latter was
* an initdb-default ACL, which changed in v15. An upgrade pulls in
* changes to most system object ACLs that the DBA had not customized.
* We've made the public schema depart from that, because changing its
* ACL so easily breaks applications.
*/ */
buildACLQueries(acl_subquery, racl_subquery, init_acl_subquery, buildACLQueries(acl_subquery, racl_subquery, init_acl_subquery,
init_racl_subquery, "n.nspacl", "n.nspowner", init_racl_subquery, "n.nspacl", "n.nspowner",
"CASE WHEN n.nspname = 'public' THEN array[" "CASE WHEN n.nspname = 'public' THEN array["
" format('%s=UC/%s', " " format('%s=UC/%s', "
" n.nspowner::regrole, n.nspowner::regrole)," " n.nspowner::regrole, n.nspowner::regrole),"
" format('=UC/%s', n.nspowner::regrole)]::aclitem[] " " format('=U/%s', n.nspowner::regrole)]::aclitem[] "
"ELSE pip.initprivs END", "ELSE pip.initprivs END",
"'n'", dopt->binary_upgrade); "'n'", dopt->binary_upgrade);

View File

@ -628,7 +628,9 @@ my %tests = (
}, },
'ALTER SCHEMA public OWNER TO' => { 'ALTER SCHEMA public OWNER TO' => {
# see test "REVOKE CREATE ON SCHEMA public" for causative create_sql create_order => 15,
create_sql =>
'ALTER SCHEMA public OWNER TO "regress_quoted \"" role";',
regexp => qr/^ALTER SCHEMA public OWNER TO .+;/m, regexp => qr/^ALTER SCHEMA public OWNER TO .+;/m,
like => { like => {
%full_runs, section_pre_data => 1, %full_runs, section_pre_data => 1,
@ -3472,17 +3474,12 @@ my %tests = (
unlike => { no_privs => 1, }, unlike => { no_privs => 1, },
}, },
'REVOKE CREATE ON SCHEMA public FROM public' => { 'REVOKE ALL ON SCHEMA public' => {
create_order => 16, create_order => 16,
create_sql => ' create_sql =>
REVOKE CREATE ON SCHEMA public FROM public; 'REVOKE ALL ON SCHEMA public FROM "regress_quoted \"" role";',
ALTER SCHEMA public OWNER TO "regress_quoted \"" role"; regexp =>
REVOKE ALL ON SCHEMA public FROM "regress_quoted \"" role";', qr/^REVOKE ALL ON SCHEMA public FROM "regress_quoted \\"" role";/m,
regexp => qr/^
\QREVOKE ALL ON SCHEMA public FROM "regress_quoted \E\\""\ role";
\n\QREVOKE ALL ON SCHEMA public FROM PUBLIC;\E
\n\QGRANT USAGE ON SCHEMA public TO PUBLIC;\E
/xm,
like => { %full_runs, section_pre_data => 1, }, like => { %full_runs, section_pre_data => 1, },
unlike => { no_privs => 1, }, unlike => { no_privs => 1, },
}, },

View File

@ -53,6 +53,6 @@
*/ */
/* yyyymmddN */ /* yyyymmddN */
#define CATALOG_VERSION_NO 202109061 #define CATALOG_VERSION_NO 202109101
#endif #endif

View File

@ -21,6 +21,6 @@
# update dumpNamespace() if changing this descr # update dumpNamespace() if changing this descr
{ oid => '2200', oid_symbol => 'PG_PUBLIC_NAMESPACE', { oid => '2200', oid_symbol => 'PG_PUBLIC_NAMESPACE',
descr => 'standard public schema', descr => 'standard public schema',
nspname => 'public', nspacl => '_null_' }, nspname => 'public', nspowner => 'pg_database_owner', nspacl => '_null_' },
] ]

View File

@ -25,6 +25,9 @@ CREATE EXTENSION plperl;
CREATE EXTENSION plperlu; -- fail CREATE EXTENSION plperlu; -- fail
ERROR: permission denied to create extension "plperlu" ERROR: permission denied to create extension "plperlu"
HINT: Must be superuser to create this extension. HINT: Must be superuser to create this extension.
CREATE SCHEMA plperl_setup_scratch;
SET search_path = plperl_setup_scratch;
GRANT ALL ON SCHEMA plperl_setup_scratch TO regress_user2;
CREATE FUNCTION foo1() returns int language plperl as '1;'; CREATE FUNCTION foo1() returns int language plperl as '1;';
SELECT foo1(); SELECT foo1();
foo1 foo1
@ -34,6 +37,7 @@ SELECT foo1();
-- Must reconnect to avoid failure with non-MULTIPLICITY Perl interpreters -- Must reconnect to avoid failure with non-MULTIPLICITY Perl interpreters
\c - \c -
SET search_path = plperl_setup_scratch;
SET ROLE regress_user1; SET ROLE regress_user1;
-- Should be able to change privileges on the language -- Should be able to change privileges on the language
revoke all on language plperl from public; revoke all on language plperl from public;

View File

@ -27,12 +27,16 @@ SET ROLE regress_user1;
CREATE EXTENSION plperl; CREATE EXTENSION plperl;
CREATE EXTENSION plperlu; -- fail CREATE EXTENSION plperlu; -- fail
CREATE SCHEMA plperl_setup_scratch;
SET search_path = plperl_setup_scratch;
GRANT ALL ON SCHEMA plperl_setup_scratch TO regress_user2;
CREATE FUNCTION foo1() returns int language plperl as '1;'; CREATE FUNCTION foo1() returns int language plperl as '1;';
SELECT foo1(); SELECT foo1();
-- Must reconnect to avoid failure with non-MULTIPLICITY Perl interpreters -- Must reconnect to avoid failure with non-MULTIPLICITY Perl interpreters
\c - \c -
SET search_path = plperl_setup_scratch;
SET ROLE regress_user1; SET ROLE regress_user1;

View File

@ -388,7 +388,7 @@ CREATE INDEX k ON testschema.tablespace_acl (c) TABLESPACE regress_tblspace;
ALTER TABLE testschema.tablespace_acl OWNER TO regress_tablespace_user2; ALTER TABLE testschema.tablespace_acl OWNER TO regress_tablespace_user2;
SET SESSION ROLE regress_tablespace_user2; SET SESSION ROLE regress_tablespace_user2;
CREATE TABLE tablespace_table (i int) TABLESPACE regress_tblspace; -- fail CREATE TEMP TABLE tablespace_table (i int) TABLESPACE regress_tblspace; -- fail
ALTER TABLE testschema.tablespace_acl ALTER c TYPE bigint; ALTER TABLE testschema.tablespace_acl ALTER c TYPE bigint;
REINDEX (TABLESPACE regress_tblspace) TABLE tablespace_table; -- fail REINDEX (TABLESPACE regress_tblspace) TABLE tablespace_table; -- fail
REINDEX (TABLESPACE regress_tblspace, CONCURRENTLY) TABLE tablespace_table; -- fail REINDEX (TABLESPACE regress_tblspace, CONCURRENTLY) TABLE tablespace_table; -- fail
@ -409,3 +409,6 @@ DROP SCHEMA testschema CASCADE;
DROP ROLE regress_tablespace_user1; DROP ROLE regress_tablespace_user1;
DROP ROLE regress_tablespace_user2; DROP ROLE regress_tablespace_user2;
-- Rest of this suite can use the public schema freely.
GRANT ALL ON SCHEMA public TO public;

View File

@ -908,7 +908,7 @@ CREATE TABLE testschema.tablespace_acl (c int);
CREATE INDEX k ON testschema.tablespace_acl (c) TABLESPACE regress_tblspace; CREATE INDEX k ON testschema.tablespace_acl (c) TABLESPACE regress_tblspace;
ALTER TABLE testschema.tablespace_acl OWNER TO regress_tablespace_user2; ALTER TABLE testschema.tablespace_acl OWNER TO regress_tablespace_user2;
SET SESSION ROLE regress_tablespace_user2; SET SESSION ROLE regress_tablespace_user2;
CREATE TABLE tablespace_table (i int) TABLESPACE regress_tblspace; -- fail CREATE TEMP TABLE tablespace_table (i int) TABLESPACE regress_tblspace; -- fail
ERROR: permission denied for tablespace regress_tblspace ERROR: permission denied for tablespace regress_tblspace
ALTER TABLE testschema.tablespace_acl ALTER c TYPE bigint; ALTER TABLE testschema.tablespace_acl ALTER c TYPE bigint;
REINDEX (TABLESPACE regress_tblspace) TABLE tablespace_table; -- fail REINDEX (TABLESPACE regress_tblspace) TABLE tablespace_table; -- fail
@ -934,3 +934,5 @@ drop cascades to table testschema.atable
drop cascades to table testschema.tablespace_acl drop cascades to table testschema.tablespace_acl
DROP ROLE regress_tablespace_user1; DROP ROLE regress_tablespace_user1;
DROP ROLE regress_tablespace_user2; DROP ROLE regress_tablespace_user2;
-- Rest of this suite can use the public schema freely.
GRANT ALL ON SCHEMA public TO public;