Add psql \drg command to display role grants.

With the addition of INHERIT and SET options for role grants,
the historical display of role memberships in \du/\dg is woefully
inadequate.  Besides those options, there are pre-existing
shortcomings that you can't see the ADMIN option nor the grantor.

To fix this, remove the "Member of" column from \du/\dg altogether
(making that output usefully narrower), and invent a new meta-command
"\drg" that is specifically for displaying role memberships.  It
shows one row for each role granted to the selected role(s), with
the grant options and grantor.

We would not normally back-patch such a feature addition post
feature freeze, but in this case the change is mainly driven by
v16 changes in the server, so it seems appropriate to include it
in v16.

Pavel Luzanov, with bikeshedding and review from a lot of people,
but particularly David Johnston

Discussion: https://postgr.es/m/b9be2d0e-a9bc-0a30-492f-a4f68e4f7740@postgrespro.ru
This commit is contained in:
Tom Lane 2023-07-19 12:46:30 -04:00
parent 245d0e6d0d
commit 0a1d2a7df8
8 changed files with 175 additions and 18 deletions

View File

@ -1883,6 +1883,7 @@ INSERT INTO tbl1 VALUES ($1, $2) \bind 'first value' 'second value' \g
</listitem>
</varlistentry>
<varlistentry id="app-psql-meta-command-drds">
<term><literal>\drds [ <link linkend="app-psql-patterns"><replaceable class="parameter">role-pattern</replaceable></link> [ <link linkend="app-psql-patterns"><replaceable class="parameter">database-pattern</replaceable></link> ] ]</literal></term>
<listitem>
@ -1905,6 +1906,27 @@ INSERT INTO tbl1 VALUES ($1, $2) \bind 'first value' 'second value' \g
</listitem>
</varlistentry>
<varlistentry id="app-psql-meta-command-drg">
<term><literal>\drg[S] [ <link linkend="app-psql-patterns"><replaceable class="parameter">pattern</replaceable></link> ]</literal></term>
<listitem>
<para>
Lists information about each granted role membership, including
assigned options (<literal>ADMIN</literal>,
<literal>INHERIT</literal> and/or <literal>SET</literal>) and grantor.
See the <link linkend="sql-grant"><command>GRANT</command></link>
command for information about role memberships.
</para>
<para>
By default, only grants to user-created roles are shown; supply the
<literal>S</literal> modifier to include system roles.
If <replaceable class="parameter">pattern</replaceable> is specified,
only grants to those roles whose names match the pattern are listed.
</para>
</listitem>
</varlistentry>
<varlistentry id="app-psql-meta-command-drp">
<term><literal>\dRp[+] [ <link linkend="app-psql-patterns"><replaceable class="parameter">pattern</replaceable></link> ]</literal></term>
<listitem>

View File

@ -918,6 +918,8 @@ exec_command_d(PsqlScanState scan_state, bool active_branch, const char *cmd)
free(pattern2);
}
else if (cmd[2] == 'g')
success = describeRoleGrants(pattern, show_system);
else
status = PSQL_CMD_UNKNOWN;
break;

View File

@ -3617,7 +3617,7 @@ describeRoles(const char *pattern, bool verbose, bool showSystem)
PGresult *res;
printTableContent cont;
printTableOpt myopt = pset.popt.topt;
int ncols = 3;
int ncols = 2;
int nrows = 0;
int i;
int conns;
@ -3631,11 +3631,7 @@ describeRoles(const char *pattern, bool verbose, bool showSystem)
printfPQExpBuffer(&buf,
"SELECT r.rolname, r.rolsuper, r.rolinherit,\n"
" r.rolcreaterole, r.rolcreatedb, r.rolcanlogin,\n"
" r.rolconnlimit, r.rolvaliduntil,\n"
" ARRAY(SELECT b.rolname\n"
" FROM pg_catalog.pg_auth_members m\n"
" JOIN pg_catalog.pg_roles b ON (m.roleid = b.oid)\n"
" WHERE m.member = r.oid) as memberof");
" r.rolconnlimit, r.rolvaliduntil");
if (verbose)
{
@ -3675,8 +3671,6 @@ describeRoles(const char *pattern, bool verbose, bool showSystem)
printTableAddHeader(&cont, gettext_noop("Role name"), true, align);
printTableAddHeader(&cont, gettext_noop("Attributes"), true, align);
/* ignores implicit memberships from superuser & pg_database_owner */
printTableAddHeader(&cont, gettext_noop("Member of"), true, align);
if (verbose)
printTableAddHeader(&cont, gettext_noop("Description"), true, align);
@ -3701,11 +3695,11 @@ describeRoles(const char *pattern, bool verbose, bool showSystem)
if (strcmp(PQgetvalue(res, i, 5), "t") != 0)
add_role_attribute(&buf, _("Cannot login"));
if (strcmp(PQgetvalue(res, i, (verbose ? 10 : 9)), "t") == 0)
if (strcmp(PQgetvalue(res, i, (verbose ? 9 : 8)), "t") == 0)
add_role_attribute(&buf, _("Replication"));
if (pset.sversion >= 90500)
if (strcmp(PQgetvalue(res, i, (verbose ? 11 : 10)), "t") == 0)
if (strcmp(PQgetvalue(res, i, (verbose ? 10 : 9)), "t") == 0)
add_role_attribute(&buf, _("Bypass RLS"));
conns = atoi(PQgetvalue(res, i, 6));
@ -3735,10 +3729,8 @@ describeRoles(const char *pattern, bool verbose, bool showSystem)
printTableAddCell(&cont, attr[i], false, false);
printTableAddCell(&cont, PQgetvalue(res, i, 8), false, false);
if (verbose)
printTableAddCell(&cont, PQgetvalue(res, i, 9), false, false);
printTableAddCell(&cont, PQgetvalue(res, i, 8), false, false);
}
termPQExpBuffer(&buf);
@ -3831,6 +3823,75 @@ error_return:
return false;
}
/*
* \drg
* Describes role grants.
*/
bool
describeRoleGrants(const char *pattern, bool showSystem)
{
PQExpBufferData buf;
PGresult *res;
printQueryOpt myopt = pset.popt;
initPQExpBuffer(&buf);
printfPQExpBuffer(&buf,
"SELECT m.rolname AS \"%s\", r.rolname AS \"%s\",\n"
" pg_catalog.concat_ws(', ',\n",
gettext_noop("Role name"),
gettext_noop("Member of"));
if (pset.sversion >= 160000)
appendPQExpBufferStr(&buf,
" CASE WHEN pam.admin_option THEN 'ADMIN' END,\n"
" CASE WHEN pam.inherit_option THEN 'INHERIT' END,\n"
" CASE WHEN pam.set_option THEN 'SET' END\n");
else
appendPQExpBufferStr(&buf,
" CASE WHEN pam.admin_option THEN 'ADMIN' END,\n"
" CASE WHEN m.rolinherit THEN 'INHERIT' END,\n"
" 'SET'\n");
appendPQExpBuffer(&buf,
" ) AS \"%s\",\n"
" g.rolname AS \"%s\"\n",
gettext_noop("Options"),
gettext_noop("Grantor"));
appendPQExpBufferStr(&buf,
"FROM pg_catalog.pg_roles m\n"
" JOIN pg_catalog.pg_auth_members pam ON (pam.member = m.oid)\n"
" LEFT JOIN pg_catalog.pg_roles r ON (pam.roleid = r.oid)\n"
" LEFT JOIN pg_catalog.pg_roles g ON (pam.grantor = g.oid)\n");
if (!showSystem && !pattern)
appendPQExpBufferStr(&buf, "WHERE m.rolname !~ '^pg_'\n");
if (!validateSQLNamePattern(&buf, pattern, false, false,
NULL, "m.rolname", NULL, NULL,
NULL, 1))
{
termPQExpBuffer(&buf);
return false;
}
appendPQExpBufferStr(&buf, "ORDER BY 1, 2, 4;\n");
res = PSQLexec(buf.data);
termPQExpBuffer(&buf);
if (!res)
return false;
myopt.nullPrint = NULL;
myopt.title = _("List of role grants");
myopt.translate_header = true;
printQuery(res, &myopt, pset.queryFout, false, pset.logfile);
PQclear(res);
return true;
}
/*
* listTables()

View File

@ -37,6 +37,9 @@ extern bool describeRoles(const char *pattern, bool verbose, bool showSystem);
/* \drds */
extern bool listDbRoleSettings(const char *pattern, const char *pattern2);
/* \drg */
extern bool describeRoleGrants(const char *pattern, bool showSystem);
/* \z (or \dp) */
extern bool permissionsList(const char *pattern, bool showSystem);

View File

@ -280,6 +280,7 @@ slashUsage(unsigned short int pager)
HELP0(" \\dp[S] [PATTERN] list table, view, and sequence access privileges\n");
HELP0(" \\dP[itn+] [PATTERN] list [only index/table] partitioned relations [n=nested]\n");
HELP0(" \\drds [ROLEPTRN [DBPTRN]] list per-database role settings\n");
HELP0(" \\drg[S] [PATTERN] list role grants\n");
HELP0(" \\dRp[+] [PATTERN] list replication publications\n");
HELP0(" \\dRs[+] [PATTERN] list replication subscriptions\n");
HELP0(" \\ds[S+] [PATTERN] list sequences\n");

View File

@ -1709,7 +1709,7 @@ psql_completion(const char *text, int start, int end)
"\\des", "\\det", "\\deu", "\\dew", "\\dE", "\\df",
"\\dF", "\\dFd", "\\dFp", "\\dFt", "\\dg", "\\di", "\\dl", "\\dL",
"\\dm", "\\dn", "\\do", "\\dO", "\\dp", "\\dP", "\\dPi", "\\dPt",
"\\drds", "\\dRs", "\\dRp", "\\ds",
"\\drds", "\\drg", "\\dRs", "\\dRp", "\\ds",
"\\dt", "\\dT", "\\dv", "\\du", "\\dx", "\\dX", "\\dy",
"\\echo", "\\edit", "\\ef", "\\elif", "\\else", "\\encoding",
"\\endif", "\\errverbose", "\\ev",
@ -4731,7 +4731,9 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tables);
else if (TailMatchesCS("\\dT*"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_datatypes);
else if (TailMatchesCS("\\du*") || TailMatchesCS("\\dg*"))
else if (TailMatchesCS("\\du*") ||
TailMatchesCS("\\dg*") ||
TailMatchesCS("\\drg*"))
COMPLETE_WITH_QUERY(Query_for_list_of_roles);
else if (TailMatchesCS("\\dv*"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_views);

View File

@ -6187,9 +6187,9 @@ List of text search templates
(0 rows)
\dg "no.such.role"
List of roles
Role name | Attributes | Member of
-----------+------------+-----------
List of roles
Role name | Attributes
-----------+------------
\dL "no.such.language"
List of languages
@ -6618,3 +6618,43 @@ cross-database references are not implemented: "no.such.database"."no.such.schem
cross-database references are not implemented: "no.such.database"."no.such.schema"."no.such.data.type"
\dX "no.such.database"."no.such.schema"."no.such.extended.statistics"
cross-database references are not implemented: "no.such.database"."no.such.schema"."no.such.extended.statistics"
-- check \drg and \du
CREATE ROLE regress_du_role0;
CREATE ROLE regress_du_role1;
CREATE ROLE regress_du_role2;
CREATE ROLE regress_du_admin;
GRANT regress_du_role0 TO regress_du_admin WITH ADMIN TRUE;
GRANT regress_du_role1 TO regress_du_admin WITH ADMIN TRUE;
GRANT regress_du_role2 TO regress_du_admin WITH ADMIN TRUE;
GRANT regress_du_role0 TO regress_du_role1 WITH ADMIN TRUE, INHERIT TRUE, SET TRUE GRANTED BY regress_du_admin;
GRANT regress_du_role0 TO regress_du_role2 WITH ADMIN TRUE, INHERIT FALSE, SET FALSE GRANTED BY regress_du_admin;
GRANT regress_du_role1 TO regress_du_role2 WITH ADMIN TRUE , INHERIT FALSE, SET TRUE GRANTED BY regress_du_admin;
GRANT regress_du_role0 TO regress_du_role1 WITH ADMIN FALSE, INHERIT TRUE, SET FALSE GRANTED BY regress_du_role1;
GRANT regress_du_role0 TO regress_du_role2 WITH ADMIN FALSE, INHERIT TRUE , SET TRUE GRANTED BY regress_du_role1;
GRANT regress_du_role0 TO regress_du_role1 WITH ADMIN FALSE, INHERIT FALSE, SET TRUE GRANTED BY regress_du_role2;
GRANT regress_du_role0 TO regress_du_role2 WITH ADMIN FALSE, INHERIT FALSE, SET FALSE GRANTED BY regress_du_role2;
\drg regress_du_role*
List of role grants
Role name | Member of | Options | Grantor
------------------+------------------+---------------------+------------------
regress_du_role1 | regress_du_role0 | ADMIN, INHERIT, SET | regress_du_admin
regress_du_role1 | regress_du_role0 | INHERIT | regress_du_role1
regress_du_role1 | regress_du_role0 | SET | regress_du_role2
regress_du_role2 | regress_du_role0 | ADMIN | regress_du_admin
regress_du_role2 | regress_du_role0 | INHERIT, SET | regress_du_role1
regress_du_role2 | regress_du_role0 | | regress_du_role2
regress_du_role2 | regress_du_role1 | ADMIN, SET | regress_du_admin
(7 rows)
\du regress_du_role*
List of roles
Role name | Attributes
------------------+--------------
regress_du_role0 | Cannot login
regress_du_role1 | Cannot login
regress_du_role2 | Cannot login
DROP ROLE regress_du_role0;
DROP ROLE regress_du_role1;
DROP ROLE regress_du_role2;
DROP ROLE regress_du_admin;

View File

@ -1823,3 +1823,29 @@ DROP FUNCTION psql_error;
\dP "no.such.database"."no.such.schema"."no.such.partitioned.relation"
\dT "no.such.database"."no.such.schema"."no.such.data.type"
\dX "no.such.database"."no.such.schema"."no.such.extended.statistics"
-- check \drg and \du
CREATE ROLE regress_du_role0;
CREATE ROLE regress_du_role1;
CREATE ROLE regress_du_role2;
CREATE ROLE regress_du_admin;
GRANT regress_du_role0 TO regress_du_admin WITH ADMIN TRUE;
GRANT regress_du_role1 TO regress_du_admin WITH ADMIN TRUE;
GRANT regress_du_role2 TO regress_du_admin WITH ADMIN TRUE;
GRANT regress_du_role0 TO regress_du_role1 WITH ADMIN TRUE, INHERIT TRUE, SET TRUE GRANTED BY regress_du_admin;
GRANT regress_du_role0 TO regress_du_role2 WITH ADMIN TRUE, INHERIT FALSE, SET FALSE GRANTED BY regress_du_admin;
GRANT regress_du_role1 TO regress_du_role2 WITH ADMIN TRUE , INHERIT FALSE, SET TRUE GRANTED BY regress_du_admin;
GRANT regress_du_role0 TO regress_du_role1 WITH ADMIN FALSE, INHERIT TRUE, SET FALSE GRANTED BY regress_du_role1;
GRANT regress_du_role0 TO regress_du_role2 WITH ADMIN FALSE, INHERIT TRUE , SET TRUE GRANTED BY regress_du_role1;
GRANT regress_du_role0 TO regress_du_role1 WITH ADMIN FALSE, INHERIT FALSE, SET TRUE GRANTED BY regress_du_role2;
GRANT regress_du_role0 TO regress_du_role2 WITH ADMIN FALSE, INHERIT FALSE, SET FALSE GRANTED BY regress_du_role2;
\drg regress_du_role*
\du regress_du_role*
DROP ROLE regress_du_role0;
DROP ROLE regress_du_role1;
DROP ROLE regress_du_role2;
DROP ROLE regress_du_admin;