or <literal>*</> for all</entry>
</row>
+ <row>
+ <entry><structfield>polpermissive</structfield></entry>
+ <entry><type>boolean</type></entry>
+ <entry></entry>
+ <entry>Is the policy permissive or restrictive?</entry>
+ </row>
+
<row>
<entry><structfield>polroles</structfield></entry>
<entry><type>oid[]</type></entry>
<entry><literal><link linkend="catalog-pg-policy"><structname>pg_policy</structname></link>.polname</literal></entry>
<entry>Name of policy</entry>
</row>
+ <row>
+ <entry><structfield>polpermissive</structfield></entry>
+ <entry><type>text</type></entry>
+ <entry></entry>
+ <entry>Is the policy permissive or restrictive?</entry>
+ </row>
<row>
<entry><structfield>roles</structfield></entry>
<entry><type>name[]</type></entry>
<para>
When multiple policies apply to a given query, they are combined using
- <literal>OR</literal>, so that a row is accessible if any policy allows
- it. This is similar to the rule that a given role has the privileges
- of all roles that they are a member of.
+ either <literal>OR</literal> (for permissive policies, which are the
+ default) or using <literal>AND</literal> (for restrictive policies).
+ This is similar to the rule that a given role has the privileges
+ of all roles that they are a member of. Permissive vs. restrictive
+ policies are discussed further below.
</para>
<para>
-- Alice can change her own password; RLS silently prevents updating other rows
postgres=> update passwd set pwhash = 'abc';
UPDATE 1
+</programlisting>
+
+ <para>
+ All of the policies constructed thus far have been permissive policies,
+ meaning that when multiple policies are applied they are combined using
+ the "OR" boolean operator. While permissive policies can be constructed
+ to only allow access to rows in the intended cases, it can be simpler to
+ combine permissive policies with restrictive policies (which the records
+ must pass and which are combined using the "AND" boolean operator).
+ Building on the example above, we add a restrictive policy to require
+ the administrator to be connected over a local unix socket to access the
+ records of the passwd table:
+ </para>
+
+<programlisting>
+CREATE POLICY admin_local_only ON passwd AS RESTRICTIVE TO admin
+ USING (pg_catalog.inet_client_addr() IS NULL);
+</programlisting>
+
+ <para>
+ We can then see that an administrator connecting over a network will not
+ see any records, due to the restrictive policy:
+ </para>
+
+<programlisting>
+=> SELECT current_user;
+ current_user
+--------------
+ admin
+(1 row)
+
+=> select inet_client_addr();
+ inet_client_addr
+------------------
+ 127.0.0.1
+(1 row)
+
+=> SELECT current_user;
+ current_user
+--------------
+ admin
+(1 row)
+
+=> TABLE passwd;
+ user_name | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell
+-----------+--------+-----+-----+-----------+------------+------------+----------+-------
+(0 rows)
+
+=> UPDATE passwd set pwhash = NULL;
+UPDATE 0
</programlisting>
<para>
<para>
<command>ALTER POLICY</command> changes the definition of an existing
- row-level security policy.
+ row-level security policy. Note that <command>ALTER POLICY</command>
+ only allows the set of roles to which the policy applies and the
+ <literal>USING</literal> and <literal>WITH CHECK</literal> expressions to
+ be modified. To change other properties of a policy, such as the command
+ to which it applies or whether it is permissive or restrictive, the policy
+ must be dropped and recreated.
</para>
<para>
<refsynopsisdiv>
<synopsis>
CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable class="parameter">table_name</replaceable>
+ [ AS { PERMISSIVE | RESTRICTIVE } ]
[ FOR { ALL | SELECT | INSERT | UPDATE | DELETE } ]
[ TO { <replaceable class="parameter">role_name</replaceable> | PUBLIC | CURRENT_USER | SESSION_USER } [, ...] ]
[ USING ( <replaceable class="parameter">using_expression</replaceable> ) ]
</listitem>
</varlistentry>
+ <varlistentry>
+ <term><replaceable class="parameter">PERMISSIVE</replaceable></term>
+ <listitem>
+ <para>
+ Specify that the policy is to be created as a permissive policy.
+ All permissive policies which are applicable to a given query will
+ be combined together using the boolean "OR" operator. By creating
+ permissive policies, administrators can add to the set of records
+ which can be accessed. Policies are PERMISSIVE by default.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable class="parameter">RESTRICTIVE</replaceable></term>
+ <listitem>
+ <para>
+ Specify that the policy is to be created as a restrictive policy.
+ All restrictive policies which are applicable to a given query will
+ be combined together using the boolean "AND" operator. By creating
+ restrictive policies, administrators can reduce the set of records
+ which can be accessed as all restrictive policies must be passed for
+ each record.
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><replaceable class="parameter">command</replaceable></term>
<listitem>
keys) instead of keys with external meanings.
</para>
+ <para>
+ Note that there needs to be at least one permissive policy to grant
+ access to records before restrictive policies can be usefully used to
+ reduce that access. If only restrictive policies exist, then no records
+ will be accessible. When a mix of permissive and restrictive policies
+ are present, a record is only accessible if at least one of the
+ permissive policies passes, in addition to all the restrictive
+ policies.
+ </para>
+
<para>
Generally, the system will enforce filter conditions imposed using
security policies prior to qualifications that appear in user queries,
N.nspname AS schemaname,
C.relname AS tablename,
pol.polname AS policyname,
+ CASE
+ WHEN pol.polpermissive THEN
+ 'PERMISSIVE'
+ ELSE
+ 'RESTRICTIVE'
+ END AS permissive,
CASE
WHEN pol.polroles = '{0}' THEN
string_to_array('public', '')
{
Datum value_datum;
char cmd_value;
+ bool permissive_value;
Datum roles_datum;
char *qual_value;
Expr *qual_expr;
Assert(!isnull);
cmd_value = DatumGetChar(value_datum);
+ /* Get policy permissive or restrictive */
+ value_datum = heap_getattr(tuple, Anum_pg_policy_polpermissive,
+ RelationGetDescr(catalog), &isnull);
+ Assert(!isnull);
+ permissive_value = DatumGetBool(value_datum);
+
/* Get policy name */
value_datum = heap_getattr(tuple, Anum_pg_policy_polname,
RelationGetDescr(catalog), &isnull);
policy = palloc0(sizeof(RowSecurityPolicy));
policy->policy_name = pstrdup(policy_name_value);
policy->polcmd = cmd_value;
+ policy->permissive = permissive_value;
policy->roles = DatumGetArrayTypePCopy(roles_datum);
policy->qual = copyObject(qual_expr);
policy->with_check_qual = copyObject(with_check_qual);
values[Anum_pg_policy_polname - 1] = DirectFunctionCall1(namein,
CStringGetDatum(stmt->policy_name));
values[Anum_pg_policy_polcmd - 1] = CharGetDatum(polcmd);
+ values[Anum_pg_policy_polpermissive - 1] = BoolGetDatum(stmt->permissive);
values[Anum_pg_policy_polroles - 1] = PointerGetDatum(role_ids);
/* Add qual if present. */
COPY_STRING_FIELD(policy_name);
COPY_NODE_FIELD(table);
COPY_STRING_FIELD(cmd_name);
+ COPY_SCALAR_FIELD(permissive);
COPY_NODE_FIELD(roles);
COPY_NODE_FIELD(qual);
COPY_NODE_FIELD(with_check);
COMPARE_STRING_FIELD(policy_name);
COMPARE_NODE_FIELD(table);
COMPARE_STRING_FIELD(cmd_name);
+ COMPARE_SCALAR_FIELD(permissive);
COMPARE_NODE_FIELD(roles);
COMPARE_NODE_FIELD(qual);
COMPARE_NODE_FIELD(with_check);
%type <str> all_Op MathOp
%type <str> row_security_cmd RowSecurityDefaultForCmd
+%type <boolean> RowSecurityDefaultPermissive
%type <node> RowSecurityOptionalWithCheck RowSecurityOptionalExpr
%type <list> RowSecurityDefaultToRole RowSecurityOptionalToRole
/*****************************************************************************
*
* QUERIES:
- * CREATE POLICY name ON table [FOR cmd] [TO role, ...]
- * [USING (qual)] [WITH CHECK (with_check)]
+ * CREATE POLICY name ON table
+ * [AS { PERMISSIVE | RESTRICTIVE } ]
+ * [FOR { SELECT | INSERT | UPDATE | DELETE } ]
+ * [TO role, ...]
+ * [USING (qual)] [WITH CHECK (with check qual)]
* ALTER POLICY name ON table [TO role, ...]
- * [USING (qual)] [WITH CHECK (with_check)]
+ * [USING (qual)] [WITH CHECK (with check qual)]
* DROP POLICY name ON table
*
*****************************************************************************/
CreatePolicyStmt:
- CREATE POLICY name ON qualified_name RowSecurityDefaultForCmd
- RowSecurityDefaultToRole RowSecurityOptionalExpr
- RowSecurityOptionalWithCheck
+ CREATE POLICY name ON qualified_name RowSecurityDefaultPermissive
+ RowSecurityDefaultForCmd RowSecurityDefaultToRole
+ RowSecurityOptionalExpr RowSecurityOptionalWithCheck
{
CreatePolicyStmt *n = makeNode(CreatePolicyStmt);
n->policy_name = $3;
n->table = $5;
- n->cmd_name = $6;
- n->roles = $7;
- n->qual = $8;
- n->with_check = $9;
+ n->permissive = $6;
+ n->cmd_name = $7;
+ n->roles = $8;
+ n->qual = $9;
+ n->with_check = $10;
$$ = (Node *) n;
}
;
| /* EMPTY */ { $$ = NULL; }
;
+RowSecurityDefaultPermissive:
+ AS IDENT
+ {
+ if (strcmp($2, "permissive") == 0)
+ $$ = true;
+ else if (strcmp($2, "restrictive") == 0)
+ $$ = false;
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_SYNTAX_ERROR),
+ errmsg("unrecognized row security option \"%s\"", $2),
+ errhint("Only PERMISSIVE or RESTRICTIVE policies are supported currently."),
+ parser_errposition(@2)));
+
+ }
+ | /* EMPTY */ { $$ = true; }
+ ;
+
RowSecurityDefaultForCmd:
FOR row_security_cmd { $$ = $2; }
| /* EMPTY */ { $$ = "all"; }
* hooks to allow extensions to add their own security policies
*
* row_security_policy_hook_permissive can be used to add policies which
- * are included in the "OR"d set of policies.
+ * are combined with the other permissive policies, using OR.
*
* row_security_policy_hook_restrictive can be used to add policies which
- * are enforced, regardless of other policies (they are "AND"d).
+ * are enforced, regardless of other policies (they are combined using AND).
*/
row_security_policy_hook_type row_security_policy_hook_permissive = NULL;
row_security_policy_hook_type row_security_policy_hook_restrictive = NULL;
/*
* For SELECT, UPDATE and DELETE, add security quals to enforce the USING
* policies. These security quals control access to existing table rows.
- * Restrictive policies are "AND"d together, and permissive policies are
- * "OR"d together.
+ * Restrictive policies are combined together using AND, and permissive
+ * policies are combined together using OR.
*/
get_policies_for_relation(rel, commandType, user_id, &permissive_policies,
* the specified role.
*/
if (cmd_matches && check_role_for_policy(policy->roles, user_id))
- *permissive_policies = lappend(*permissive_policies, policy);
+ {
+ if (policy->permissive)
+ *permissive_policies = lappend(*permissive_policies, policy);
+ else
+ *restrictive_policies = lappend(*restrictive_policies, policy);
+ }
}
+ /*
+ * We sort restrictive policies by name so that any WCOs they generate are
+ * checked in a well-defined order.
+ */
+ *restrictive_policies = sort_policies_by_name(*restrictive_policies);
+
/*
* Then add any permissive or restrictive policies defined by extensions.
* These are simply appended to the lists of internal policies, if they
(*row_security_policy_hook_restrictive) (cmd, relation);
/*
- * We sort restrictive policies by name so that any WCOs they generate
- * are checked in a well-defined order.
+ * As with built-in restrictive policies, we sort any hook-provided
+ * restrictive policies by name also. Note that we also intentionally
+ * always check all built-in restrictive policies, in name order,
+ * before checking restrictive policies added by hooks, in name order.
*/
hook_policies = sort_policies_by_name(hook_policies);
*
* This is only used for restrictive policies, ensuring that any
* WithCheckOptions they generate are applied in a well-defined order.
- * This is not necessary for permissive policies, since they are all "OR"d
- * together into a single WithCheckOption check.
+ * This is not necessary for permissive policies, since they are all combined
+ * together using OR into a single WithCheckOption check.
*/
static List *
sort_policies_by_name(List *policies)
/*
* We now know that permissive policies exist, so we can now add
* security quals based on the USING clauses from the restrictive
- * policies. Since these need to be "AND"d together, we can just add
- * them one at a time.
+ * policies. Since these need to be combined together using AND, we
+ * can just add them one at a time.
*/
foreach(item, restrictive_policies)
{
}
/*
- * Then add a single security qual "OR"ing together the USING clauses
- * from all the permissive policies.
+ * Then add a single security qual combining together the USING
+ * clauses from all the permissive policies using OR.
*/
if (list_length(permissive_quals) == 1)
rowsec_expr = (Expr *) linitial(permissive_quals);
if (permissive_quals != NIL)
{
/*
- * Add a single WithCheckOption for all the permissive policy clauses
- * "OR"d together. This check has no policy name, since if the check
- * fails it means that no policy granted permission to perform the
- * update, rather than any particular policy being violated.
+ * Add a single WithCheckOption for all the permissive policy clauses,
+ * combining them together using OR. This check has no policy name,
+ * since if the check fails it means that no policy granted permission
+ * to perform the update, rather than any particular policy being
+ * violated.
*/
WithCheckOption *wco;
/*
* Now add WithCheckOptions for each of the restrictive policy clauses
- * (which will be "AND"d together). We use a separate WithCheckOption
- * for each restrictive policy to allow the policy name to be included
- * in error reports if the policy is violated.
+ * (which will be combined together using AND). We use a separate
+ * WithCheckOption for each restrictive policy to allow the policy
+ * name to be included in error reports if the policy is violated.
*/
foreach(item, restrictive_policies)
{
int i_tableoid;
int i_polname;
int i_polcmd;
+ int i_polpermissive;
int i_polroles;
int i_polqual;
int i_polwithcheck;
polinfo->dobj.name = pg_strdup(tbinfo->dobj.name);
polinfo->poltable = tbinfo;
polinfo->polname = NULL;
- polinfo->polcmd = NULL;
+ polinfo->polcmd = '\0';
+ polinfo->polpermissive = 0;
polinfo->polroles = NULL;
polinfo->polqual = NULL;
polinfo->polwithcheck = NULL;
resetPQExpBuffer(query);
/* Get the policies for the table. */
- appendPQExpBuffer(query,
- "SELECT oid, tableoid, pol.polname, pol.polcmd, "
- "CASE WHEN pol.polroles = '{0}' THEN 'PUBLIC' ELSE "
- " pg_catalog.array_to_string(ARRAY(SELECT pg_catalog.quote_ident(rolname) from pg_catalog.pg_roles WHERE oid = ANY(pol.polroles)), ', ') END AS polroles, "
- "pg_catalog.pg_get_expr(pol.polqual, pol.polrelid) AS polqual, "
- "pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid) AS polwithcheck "
- "FROM pg_catalog.pg_policy pol "
- "WHERE polrelid = '%u'",
- tbinfo->dobj.catId.oid);
+ if (fout->remoteVersion >= 100000)
+ appendPQExpBuffer(query,
+ "SELECT oid, tableoid, pol.polname, pol.polcmd, pol.polpermissive, "
+ "CASE WHEN pol.polroles = '{0}' THEN NULL ELSE "
+ " pg_catalog.array_to_string(ARRAY(SELECT pg_catalog.quote_ident(rolname) from pg_catalog.pg_roles WHERE oid = ANY(pol.polroles)), ', ') END AS polroles, "
+ "pg_catalog.pg_get_expr(pol.polqual, pol.polrelid) AS polqual, "
+ "pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid) AS polwithcheck "
+ "FROM pg_catalog.pg_policy pol "
+ "WHERE polrelid = '%u'",
+ tbinfo->dobj.catId.oid);
+ else
+ appendPQExpBuffer(query,
+ "SELECT oid, tableoid, pol.polname, pol.polcmd, 't' as polpermissive, "
+ "CASE WHEN pol.polroles = '{0}' THEN NULL ELSE "
+ " pg_catalog.array_to_string(ARRAY(SELECT pg_catalog.quote_ident(rolname) from pg_catalog.pg_roles WHERE oid = ANY(pol.polroles)), ', ') END AS polroles, "
+ "pg_catalog.pg_get_expr(pol.polqual, pol.polrelid) AS polqual, "
+ "pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid) AS polwithcheck "
+ "FROM pg_catalog.pg_policy pol "
+ "WHERE polrelid = '%u'",
+ tbinfo->dobj.catId.oid);
res = ExecuteSqlQuery(fout, query->data, PGRES_TUPLES_OK);
ntups = PQntuples(res);
i_tableoid = PQfnumber(res, "tableoid");
i_polname = PQfnumber(res, "polname");
i_polcmd = PQfnumber(res, "polcmd");
+ i_polpermissive = PQfnumber(res, "polpermissive");
i_polroles = PQfnumber(res, "polroles");
i_polqual = PQfnumber(res, "polqual");
i_polwithcheck = PQfnumber(res, "polwithcheck");
polinfo[j].polname = pg_strdup(PQgetvalue(res, j, i_polname));
polinfo[j].dobj.name = pg_strdup(polinfo[j].polname);
- polinfo[j].polcmd = pg_strdup(PQgetvalue(res, j, i_polcmd));
- polinfo[j].polroles = pg_strdup(PQgetvalue(res, j, i_polroles));
+ polinfo[j].polcmd = *(PQgetvalue(res, j, i_polcmd));
+ polinfo[j].polpermissive = *(PQgetvalue(res, j, i_polpermissive)) == 't';
+
+ if (PQgetisnull(res, j, i_polroles))
+ polinfo[j].polroles = NULL;
+ else
+ polinfo[j].polroles = pg_strdup(PQgetvalue(res, j, i_polroles));
if (PQgetisnull(res, j, i_polqual))
polinfo[j].polqual = NULL;
return;
}
- if (strcmp(polinfo->polcmd, "*") == 0)
- cmd = "ALL";
- else if (strcmp(polinfo->polcmd, "r") == 0)
- cmd = "SELECT";
- else if (strcmp(polinfo->polcmd, "a") == 0)
- cmd = "INSERT";
- else if (strcmp(polinfo->polcmd, "w") == 0)
- cmd = "UPDATE";
- else if (strcmp(polinfo->polcmd, "d") == 0)
- cmd = "DELETE";
+ if (polinfo->polcmd == '*')
+ cmd = "";
+ else if (polinfo->polcmd == 'r')
+ cmd = " FOR SELECT";
+ else if (polinfo->polcmd == 'a')
+ cmd = " FOR INSERT";
+ else if (polinfo->polcmd == 'w')
+ cmd = " FOR UPDATE";
+ else if (polinfo->polcmd == 'd')
+ cmd = " FOR DELETE";
else
{
- write_msg(NULL, "unexpected policy command type: \"%s\"\n",
+ write_msg(NULL, "unexpected policy command type: %c\n",
polinfo->polcmd);
exit_nicely(1);
}
delqry = createPQExpBuffer();
appendPQExpBuffer(query, "CREATE POLICY %s", fmtId(polinfo->polname));
- appendPQExpBuffer(query, " ON %s FOR %s", fmtId(tbinfo->dobj.name), cmd);
+
+ appendPQExpBuffer(query, " ON %s%s%s", fmtId(tbinfo->dobj.name),
+ !polinfo->polpermissive ? " AS RESTRICTIVE" : "", cmd);
if (polinfo->polroles != NULL)
appendPQExpBuffer(query, " TO %s", polinfo->polroles);
DumpableObject dobj;
TableInfo *poltable;
char *polname; /* null indicates RLS is enabled on rel */
- char *polcmd;
+ char polcmd;
+ bool polpermissive;
char *polroles;
char *polqual;
char *polwithcheck;
USING (true)
WITH CHECK (true);',
regexp => qr/^
- \QCREATE POLICY p1 ON test_table FOR ALL TO PUBLIC \E
+ \QCREATE POLICY p1 ON test_table \E
\QUSING (true) WITH CHECK (true);\E
/xm,
like => {
pg_dumpall_globals_clean => 1,
role => 1,
section_pre_data => 1, }, },
-
+ 'CREATE POLICY p6 ON test_table AS RESTRICTIVE' => {
+ create_order => 27,
+ create_sql => 'CREATE POLICY p6 ON dump_test.test_table AS RESTRICTIVE
+ USING (false);',
+ regexp => qr/^
+ \QCREATE POLICY p6 ON test_table AS RESTRICTIVE \E
+ \QUSING (false);\E
+ /xm,
+ like => {
+ binary_upgrade => 1,
+ clean => 1,
+ clean_if_exists => 1,
+ createdb => 1,
+ defaults => 1,
+ exclude_test_table_data => 1,
+ no_privs => 1,
+ no_owner => 1,
+ only_dump_test_schema => 1,
+ only_dump_test_table => 1,
+ pg_dumpall_dbprivs => 1,
+ schema_only => 1,
+ section_post_data => 1,
+ test_schema_plus_blobs => 1, },
+ unlike => {
+ exclude_dump_test_schema => 1,
+ exclude_test_table => 1,
+ pg_dumpall_globals => 1,
+ pg_dumpall_globals_clean => 1,
+ role => 1,
+ section_pre_data => 1, }, },
'CREATE SCHEMA dump_test' => {
all_runs => 1,
catch_all => 'CREATE ... commands',
" ), E'\\n') AS \"%s\"",
gettext_noop("Column privileges"));
- if (pset.sversion >= 90500)
+ if (pset.sversion >= 90500 && pset.sversion < 100000)
+ appendPQExpBuffer(&buf,
+ ",\n pg_catalog.array_to_string(ARRAY(\n"
+ " SELECT polname\n"
+ " || CASE WHEN polcmd != '*' THEN\n"
+ " E' (' || polcmd || E'):'\n"
+ " ELSE E':' \n"
+ " END\n"
+ " || CASE WHEN polqual IS NOT NULL THEN\n"
+ " E'\\n (u): ' || pg_catalog.pg_get_expr(polqual, polrelid)\n"
+ " ELSE E''\n"
+ " END\n"
+ " || CASE WHEN polwithcheck IS NOT NULL THEN\n"
+ " E'\\n (c): ' || pg_catalog.pg_get_expr(polwithcheck, polrelid)\n"
+ " ELSE E''\n"
+ " END"
+ " || CASE WHEN polroles <> '{0}' THEN\n"
+ " E'\\n to: ' || pg_catalog.array_to_string(\n"
+ " ARRAY(\n"
+ " SELECT rolname\n"
+ " FROM pg_catalog.pg_roles\n"
+ " WHERE oid = ANY (polroles)\n"
+ " ORDER BY 1\n"
+ " ), E', ')\n"
+ " ELSE E''\n"
+ " END\n"
+ " FROM pg_catalog.pg_policy pol\n"
+ " WHERE polrelid = c.oid), E'\\n')\n"
+ " AS \"%s\"",
+ gettext_noop("Policies"));
+
+ if (pset.sversion >= 100000)
appendPQExpBuffer(&buf,
",\n pg_catalog.array_to_string(ARRAY(\n"
" SELECT polname\n"
+ " || CASE WHEN NOT polpermissive THEN\n"
+ " E' (RESTRICTIVE)'\n"
+ " ELSE '' END\n"
" || CASE WHEN polcmd != '*' THEN\n"
" E' (' || polcmd || E'):'\n"
" ELSE E':' \n"
/* print any row-level policies */
if (pset.sversion >= 90500)
{
- printfPQExpBuffer(&buf,
- "SELECT pol.polname,\n"
- "CASE WHEN pol.polroles = '{0}' THEN NULL ELSE array_to_string(array(select rolname from pg_roles where oid = any (pol.polroles) order by 1),',') END,\n"
- "pg_catalog.pg_get_expr(pol.polqual, pol.polrelid),\n"
- "pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid),\n"
- "CASE pol.polcmd \n"
- "WHEN 'r' THEN 'SELECT'\n"
- "WHEN 'a' THEN 'INSERT'\n"
- "WHEN 'w' THEN 'UPDATE'\n"
- "WHEN 'd' THEN 'DELETE'\n"
- "WHEN '*' THEN 'ALL'\n"
- "END AS cmd\n"
- "FROM pg_catalog.pg_policy pol\n"
- "WHERE pol.polrelid = '%s' ORDER BY 1;",
- oid);
+ if (pset.sversion >= 100000)
+ printfPQExpBuffer(&buf,
+ "SELECT pol.polname, pol.polpermissive,\n"
+ "CASE WHEN pol.polroles = '{0}' THEN NULL ELSE array_to_string(array(select rolname from pg_roles where oid = any (pol.polroles) order by 1),',') END,\n"
+ "pg_catalog.pg_get_expr(pol.polqual, pol.polrelid),\n"
+ "pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid),\n"
+ "CASE pol.polcmd \n"
+ "WHEN 'r' THEN 'SELECT'\n"
+ "WHEN 'a' THEN 'INSERT'\n"
+ "WHEN 'w' THEN 'UPDATE'\n"
+ "WHEN 'd' THEN 'DELETE'\n"
+ "END AS cmd\n"
+ "FROM pg_catalog.pg_policy pol\n"
+ "WHERE pol.polrelid = '%s' ORDER BY 1;",
+ oid);
+ else
+ printfPQExpBuffer(&buf,
+ "SELECT pol.polname, 't' as polpermissive,\n"
+ "CASE WHEN pol.polroles = '{0}' THEN NULL ELSE array_to_string(array(select rolname from pg_roles where oid = any (pol.polroles) order by 1),',') END,\n"
+ "pg_catalog.pg_get_expr(pol.polqual, pol.polrelid),\n"
+ "pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid),\n"
+ "CASE pol.polcmd \n"
+ "WHEN 'r' THEN 'SELECT'\n"
+ "WHEN 'a' THEN 'INSERT'\n"
+ "WHEN 'w' THEN 'UPDATE'\n"
+ "WHEN 'd' THEN 'DELETE'\n"
+ "END AS cmd\n"
+ "FROM pg_catalog.pg_policy pol\n"
+ "WHERE pol.polrelid = '%s' ORDER BY 1;",
+ oid);
result = PSQLexec(buf.data);
if (!result)
printfPQExpBuffer(&buf, " POLICY \"%s\"",
PQgetvalue(result, i, 0));
- if (!PQgetisnull(result, i, 4))
+ if (*(PQgetvalue(result, i, 1)) == 'f')
+ appendPQExpBuffer(&buf, " AS RESTRICTIVE");
+
+ if (!PQgetisnull(result, i, 5))
appendPQExpBuffer(&buf, " FOR %s",
- PQgetvalue(result, i, 4));
+ PQgetvalue(result, i, 5));
- if (!PQgetisnull(result, i, 1))
+ if (!PQgetisnull(result, i, 2))
{
appendPQExpBuffer(&buf, "\n TO %s",
- PQgetvalue(result, i, 1));
+ PQgetvalue(result, i, 2));
}
- if (!PQgetisnull(result, i, 2))
+ if (!PQgetisnull(result, i, 3))
appendPQExpBuffer(&buf, "\n USING (%s)",
- PQgetvalue(result, i, 2));
+ PQgetvalue(result, i, 3));
- if (!PQgetisnull(result, i, 3))
+ if (!PQgetisnull(result, i, 4))
appendPQExpBuffer(&buf, "\n WITH CHECK (%s)",
- PQgetvalue(result, i, 3));
+ PQgetvalue(result, i, 4));
printTableAddFooter(&cont, buf.data);
/* Complete "CREATE POLICY <name> ON <table>" */
else if (Matches4("CREATE", "POLICY", MatchAny, "ON"))
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tables, NULL);
- /* Complete "CREATE POLICY <name> ON <table> FOR|TO|USING|WITH CHECK" */
+ /* Complete "CREATE POLICY <name> ON <table> AS|FOR|TO|USING|WITH CHECK" */
else if (Matches5("CREATE", "POLICY", MatchAny, "ON", MatchAny))
- COMPLETE_WITH_LIST4("FOR", "TO", "USING (", "WITH CHECK (");
+ COMPLETE_WITH_LIST5("AS", "FOR", "TO", "USING (", "WITH CHECK (");
+ /* CREATE POLICY <name> ON <table> AS PERMISSIVE|RESTRICTIVE */
+ else if (Matches6("CREATE", "POLICY", MatchAny, "ON", MatchAny, "AS"))
+ COMPLETE_WITH_LIST2("PERMISSIVE", "RESTRICTIVE");
+ /* CREATE POLICY <name> ON <table> AS PERMISSIVE|RESTRICTIVE FOR|TO|USING|WITH CHECK */
+ else if (Matches7("CREATE", "POLICY", MatchAny, "ON", MatchAny, "AS", MatchAny))
+ COMPLETE_WITH_LIST4("FOR", "TO", "USING", "WITH CHECK");
/* CREATE POLICY <name> ON <table> FOR ALL|SELECT|INSERT|UPDATE|DELETE */
else if (Matches6("CREATE", "POLICY", MatchAny, "ON", MatchAny, "FOR"))
COMPLETE_WITH_LIST5("ALL", "SELECT", "INSERT", "UPDATE", "DELETE");
/* Complete "CREATE POLICY <name> ON <table> USING (" */
else if (Matches6("CREATE", "POLICY", MatchAny, "ON", MatchAny, "USING"))
COMPLETE_WITH_CONST("(");
+ /* CREATE POLICY <name> ON <table> AS PERMISSIVE|RESTRICTIVE FOR ALL|SELECT|INSERT|UPDATE|DELETE */
+ else if (Matches8("CREATE", "POLICY", MatchAny, "ON", MatchAny, "AS", MatchAny, "FOR"))
+ COMPLETE_WITH_LIST5("ALL", "SELECT", "INSERT", "UPDATE", "DELETE");
+ /* Complete "CREATE POLICY <name> ON <table> AS PERMISSIVE|RESTRICTIVE FOR INSERT TO|WITH CHECK" */
+ else if (Matches9("CREATE", "POLICY", MatchAny, "ON", MatchAny, "AS", MatchAny, "FOR", "INSERT"))
+ COMPLETE_WITH_LIST2("TO", "WITH CHECK (");
+ /* Complete "CREATE POLICY <name> ON <table> AS PERMISSIVE|RESTRICTIVE FOR SELECT|DELETE TO|USING" */
+ else if (Matches9("CREATE", "POLICY", MatchAny, "ON", MatchAny, "AS", MatchAny, "FOR", "SELECT|DELETE"))
+ COMPLETE_WITH_LIST2("TO", "USING (");
+ /* CREATE POLICY <name> ON <table> AS PERMISSIVE|RESTRICTIVE FOR ALL|UPDATE TO|USING|WITH CHECK */
+ else if (Matches9("CREATE", "POLICY", MatchAny, "ON", MatchAny, "AS", MatchAny, "FOR", "ALL|UPDATE"))
+ COMPLETE_WITH_LIST3("TO", "USING (", "WITH CHECK (");
+ /* Complete "CREATE POLICY <name> ON <table> AS PERMISSIVE|RESTRICTIVE TO <role>" */
+ else if (Matches8("CREATE", "POLICY", MatchAny, "ON", MatchAny, "AS", MatchAny, "TO"))
+ COMPLETE_WITH_QUERY(Query_for_list_of_grant_roles);
+ /* Complete "CREATE POLICY <name> ON <table> AS PERMISSIVE|RESTRICTIVE USING (" */
+ else if (Matches8("CREATE", "POLICY", MatchAny, "ON", MatchAny, "AS", MatchAny, "USING"))
+ COMPLETE_WITH_CONST("(");
+
/* CREATE RULE */
/* Complete "CREATE RULE <sth>" with "AS ON" */
NameData polname; /* Policy name. */
Oid polrelid; /* Oid of the relation with policy. */
char polcmd; /* One of ACL_*_CHR, or '*' for all */
+ bool polpermissive; /* restrictive or permissive policy */
#ifdef CATALOG_VARLEN
Oid polroles[1]; /* Roles associated with policy, not-NULL */
* compiler constants for pg_policy
* ----------------
*/
-#define Natts_pg_policy 6
-#define Anum_pg_policy_polname 1
-#define Anum_pg_policy_polrelid 2
-#define Anum_pg_policy_polcmd 3
-#define Anum_pg_policy_polroles 4
-#define Anum_pg_policy_polqual 5
-#define Anum_pg_policy_polwithcheck 6
+#define Natts_pg_policy 7
+#define Anum_pg_policy_polname 1
+#define Anum_pg_policy_polrelid 2
+#define Anum_pg_policy_polcmd 3
+#define Anum_pg_policy_polpermissive 4
+#define Anum_pg_policy_polroles 5
+#define Anum_pg_policy_polqual 6
+#define Anum_pg_policy_polwithcheck 7
#endif /* PG_POLICY_H */
char *policy_name; /* Policy's name */
RangeVar *table; /* the table name the policy applies to */
char *cmd_name; /* the command name the policy applies to */
+ bool permissive; /* restrictive or permissive policy */
List *roles; /* the roles associated with the policy */
Node *qual; /* the policy's condition */
Node *with_check; /* the policy's WITH CHECK condition. */
char *policy_name; /* Name of the policy */
char polcmd; /* Type of command policy is for */
ArrayType *roles; /* Array of roles policy is for */
+ bool permissive; /* restrictive or permissive policy */
Expr *qual; /* Expression to filter rows */
Expr *with_check_qual; /* Expression to limit rows allowed */
bool hassublinks; /* If either expression has sublinks */
DROP USER IF EXISTS regress_rls_alice;
DROP USER IF EXISTS regress_rls_bob;
DROP USER IF EXISTS regress_rls_carol;
+DROP USER IF EXISTS regress_rls_dave;
DROP USER IF EXISTS regress_rls_exempt_user;
DROP ROLE IF EXISTS regress_rls_group1;
DROP ROLE IF EXISTS regress_rls_group2;
CREATE USER regress_rls_alice NOLOGIN;
CREATE USER regress_rls_bob NOLOGIN;
CREATE USER regress_rls_carol NOLOGIN;
+CREATE USER regress_rls_dave NOLOGIN;
CREATE USER regress_rls_exempt_user BYPASSRLS NOLOGIN;
CREATE ROLE regress_rls_group1 NOLOGIN;
CREATE ROLE regress_rls_group2 NOLOGIN;
( 5, 44, 2, 'regress_rls_bob', 'my second manga'),
( 6, 22, 1, 'regress_rls_carol', 'great science fiction'),
( 7, 33, 2, 'regress_rls_carol', 'great technology book'),
- ( 8, 44, 1, 'regress_rls_carol', 'great manga');
+ ( 8, 44, 1, 'regress_rls_carol', 'great manga'),
+ ( 9, 22, 1, 'regress_rls_dave', 'awesome science fiction'),
+ (10, 33, 2, 'regress_rls_dave', 'awesome technology book');
ALTER TABLE document ENABLE ROW LEVEL SECURITY;
-- user's security level must be higher than or equal to document's
-CREATE POLICY p1 ON document
+CREATE POLICY p1 ON document AS PERMISSIVE
USING (dlevel <= (SELECT seclv FROM uaccount WHERE pguser = current_user));
+-- try to create a policy of bogus type
+CREATE POLICY p1 ON document AS UGLY
+ USING (dlevel <= (SELECT seclv FROM uaccount WHERE pguser = current_user));
+ERROR: unrecognized row security option "ugly"
+LINE 1: CREATE POLICY p1 ON document AS UGLY
+ ^
+HINT: Only PERMISSIVE or RESTRICTIVE policies are supported currently.
+-- but Dave isn't allowed to anything at cid 50 or above
+-- this is to make sure that we sort the policies by name first
+-- when applying WITH CHECK, a later INSERT by Dave should fail due
+-- to p1r first
+CREATE POLICY p2r ON document AS RESTRICTIVE TO regress_rls_dave
+ USING (cid <> 44 AND cid < 50);
+-- and Dave isn't allowed to see manga documents
+CREATE POLICY p1r ON document AS RESTRICTIVE TO regress_rls_dave
+ USING (cid <> 44);
+\dp
+ Access privileges
+ Schema | Name | Type | Access privileges | Column privileges | Policies
+--------------------+----------+-------+---------------------------------------------+-------------------+--------------------------------------------
+ regress_rls_schema | category | table | regress_rls_alice=arwdDxt/regress_rls_alice+| |
+ | | | =arwdDxt/regress_rls_alice | |
+ regress_rls_schema | document | table | regress_rls_alice=arwdDxt/regress_rls_alice+| | p1: +
+ | | | =arwdDxt/regress_rls_alice | | (u): (dlevel <= ( SELECT uaccount.seclv +
+ | | | | | FROM uaccount +
+ | | | | | WHERE (uaccount.pguser = CURRENT_USER)))+
+ | | | | | p2r (RESTRICTIVE): +
+ | | | | | (u): ((cid <> 44) AND (cid < 50)) +
+ | | | | | to: regress_rls_dave +
+ | | | | | p1r (RESTRICTIVE): +
+ | | | | | (u): (cid <> 44) +
+ | | | | | to: regress_rls_dave
+ regress_rls_schema | uaccount | table | regress_rls_alice=arwdDxt/regress_rls_alice+| |
+ | | | =r/regress_rls_alice | |
+(3 rows)
+
+\d document
+ Table "regress_rls_schema.document"
+ Column | Type | Collation | Nullable | Default
+---------+---------+-----------+----------+---------
+ did | integer | | not null |
+ cid | integer | | |
+ dlevel | integer | | not null |
+ dauthor | name | | |
+ dtitle | text | | |
+Indexes:
+ "document_pkey" PRIMARY KEY, btree (did)
+Foreign-key constraints:
+ "document_cid_fkey" FOREIGN KEY (cid) REFERENCES category(cid)
+Policies:
+ POLICY "p1"
+ USING ((dlevel <= ( SELECT uaccount.seclv
+ FROM uaccount
+ WHERE (uaccount.pguser = CURRENT_USER))))
+ POLICY "p1r" AS RESTRICTIVE
+ TO regress_rls_dave
+ USING ((cid <> 44))
+ POLICY "p2r" AS RESTRICTIVE
+ TO regress_rls_dave
+ USING (((cid <> 44) AND (cid < 50)))
+
+SELECT * FROM pg_policies WHERE schemaname = 'regress_rls_schema' AND tablename = 'document' ORDER BY policyname;
+ schemaname | tablename | policyname | permissive | roles | cmd | qual | with_check
+--------------------+-----------+------------+-------------+--------------------+-----+--------------------------------------------+------------
+ regress_rls_schema | document | p1 | PERMISSIVE | {public} | ALL | (dlevel <= ( SELECT uaccount.seclv +|
+ | | | | | | FROM uaccount +|
+ | | | | | | WHERE (uaccount.pguser = CURRENT_USER))) |
+ regress_rls_schema | document | p1r | RESTRICTIVE | {regress_rls_dave} | ALL | (cid <> 44) |
+ regress_rls_schema | document | p2r | RESTRICTIVE | {regress_rls_dave} | ALL | ((cid <> 44) AND (cid < 50)) |
+(3 rows)
+
-- viewpoint from regress_rls_bob
SET SESSION AUTHORIZATION regress_rls_bob;
SET row_security TO ON;
NOTICE: f_leak => my first manga
NOTICE: f_leak => great science fiction
NOTICE: f_leak => great manga
- did | cid | dlevel | dauthor | dtitle
------+-----+--------+-------------------+-----------------------
+NOTICE: f_leak => awesome science fiction
+ did | cid | dlevel | dauthor | dtitle
+-----+-----+--------+-------------------+-------------------------
1 | 11 | 1 | regress_rls_bob | my first novel
4 | 44 | 1 | regress_rls_bob | my first manga
6 | 22 | 1 | regress_rls_carol | great science fiction
8 | 44 | 1 | regress_rls_carol | great manga
-(4 rows)
+ 9 | 22 | 1 | regress_rls_dave | awesome science fiction
+(5 rows)
SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER BY did;
NOTICE: f_leak => my first novel
NOTICE: f_leak => my first manga
NOTICE: f_leak => great science fiction
NOTICE: f_leak => great manga
- cid | did | dlevel | dauthor | dtitle | cname
------+-----+--------+-------------------+-----------------------+-----------------
- 11 | 1 | 1 | regress_rls_bob | my first novel | novel
- 44 | 4 | 1 | regress_rls_bob | my first manga | manga
- 22 | 6 | 1 | regress_rls_carol | great science fiction | science fiction
- 44 | 8 | 1 | regress_rls_carol | great manga | manga
-(4 rows)
+NOTICE: f_leak => awesome science fiction
+ cid | did | dlevel | dauthor | dtitle | cname
+-----+-----+--------+-------------------+-------------------------+-----------------
+ 11 | 1 | 1 | regress_rls_bob | my first novel | novel
+ 44 | 4 | 1 | regress_rls_bob | my first manga | manga
+ 22 | 6 | 1 | regress_rls_carol | great science fiction | science fiction
+ 44 | 8 | 1 | regress_rls_carol | great manga | manga
+ 22 | 9 | 1 | regress_rls_dave | awesome science fiction | science fiction
+(5 rows)
-- try a sampled version
SELECT * FROM document TABLESAMPLE BERNOULLI(50) REPEATABLE(0)
NOTICE: f_leak => my first manga
NOTICE: f_leak => great science fiction
NOTICE: f_leak => great manga
- did | cid | dlevel | dauthor | dtitle
------+-----+--------+-------------------+-----------------------
+NOTICE: f_leak => awesome science fiction
+ did | cid | dlevel | dauthor | dtitle
+-----+-----+--------+-------------------+-------------------------
4 | 44 | 1 | regress_rls_bob | my first manga
6 | 22 | 1 | regress_rls_carol | great science fiction
8 | 44 | 1 | regress_rls_carol | great manga
-(3 rows)
+ 9 | 22 | 1 | regress_rls_dave | awesome science fiction
+(4 rows)
-- viewpoint from regress_rls_carol
SET SESSION AUTHORIZATION regress_rls_carol;
NOTICE: f_leak => great science fiction
NOTICE: f_leak => great technology book
NOTICE: f_leak => great manga
- did | cid | dlevel | dauthor | dtitle
------+-----+--------+-------------------+-----------------------
+NOTICE: f_leak => awesome science fiction
+NOTICE: f_leak => awesome technology book
+ did | cid | dlevel | dauthor | dtitle
+-----+-----+--------+-------------------+-------------------------
1 | 11 | 1 | regress_rls_bob | my first novel
2 | 11 | 2 | regress_rls_bob | my second novel
3 | 22 | 2 | regress_rls_bob | my science fiction
6 | 22 | 1 | regress_rls_carol | great science fiction
7 | 33 | 2 | regress_rls_carol | great technology book
8 | 44 | 1 | regress_rls_carol | great manga
-(8 rows)
+ 9 | 22 | 1 | regress_rls_dave | awesome science fiction
+ 10 | 33 | 2 | regress_rls_dave | awesome technology book
+(10 rows)
SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER BY did;
NOTICE: f_leak => my first novel
NOTICE: f_leak => great science fiction
NOTICE: f_leak => great technology book
NOTICE: f_leak => great manga
- cid | did | dlevel | dauthor | dtitle | cname
------+-----+--------+-------------------+-----------------------+-----------------
- 11 | 1 | 1 | regress_rls_bob | my first novel | novel
- 11 | 2 | 2 | regress_rls_bob | my second novel | novel
- 22 | 3 | 2 | regress_rls_bob | my science fiction | science fiction
- 44 | 4 | 1 | regress_rls_bob | my first manga | manga
- 44 | 5 | 2 | regress_rls_bob | my second manga | manga
- 22 | 6 | 1 | regress_rls_carol | great science fiction | science fiction
- 33 | 7 | 2 | regress_rls_carol | great technology book | technology
- 44 | 8 | 1 | regress_rls_carol | great manga | manga
-(8 rows)
+NOTICE: f_leak => awesome science fiction
+NOTICE: f_leak => awesome technology book
+ cid | did | dlevel | dauthor | dtitle | cname
+-----+-----+--------+-------------------+-------------------------+-----------------
+ 11 | 1 | 1 | regress_rls_bob | my first novel | novel
+ 11 | 2 | 2 | regress_rls_bob | my second novel | novel
+ 22 | 3 | 2 | regress_rls_bob | my science fiction | science fiction
+ 44 | 4 | 1 | regress_rls_bob | my first manga | manga
+ 44 | 5 | 2 | regress_rls_bob | my second manga | manga
+ 22 | 6 | 1 | regress_rls_carol | great science fiction | science fiction
+ 33 | 7 | 2 | regress_rls_carol | great technology book | technology
+ 44 | 8 | 1 | regress_rls_carol | great manga | manga
+ 22 | 9 | 1 | regress_rls_dave | awesome science fiction | science fiction
+ 33 | 10 | 2 | regress_rls_dave | awesome technology book | technology
+(10 rows)
-- try a sampled version
SELECT * FROM document TABLESAMPLE BERNOULLI(50) REPEATABLE(0)
NOTICE: f_leak => my second manga
NOTICE: f_leak => great science fiction
NOTICE: f_leak => great manga
- did | cid | dlevel | dauthor | dtitle
------+-----+--------+-------------------+-----------------------
+NOTICE: f_leak => awesome science fiction
+ did | cid | dlevel | dauthor | dtitle
+-----+-----+--------+-------------------+-------------------------
4 | 44 | 1 | regress_rls_bob | my first manga
5 | 44 | 2 | regress_rls_bob | my second manga
6 | 22 | 1 | regress_rls_carol | great science fiction
8 | 44 | 1 | regress_rls_carol | great manga
-(4 rows)
+ 9 | 22 | 1 | regress_rls_dave | awesome science fiction
+(5 rows)
EXPLAIN (COSTS OFF) SELECT * FROM document WHERE f_leak(dtitle);
QUERY PLAN
Index Cond: (pguser = CURRENT_USER)
(11 rows)
+-- viewpoint from regress_rls_dave
+SET SESSION AUTHORIZATION regress_rls_dave;
+SELECT * FROM document WHERE f_leak(dtitle) ORDER BY did;
+NOTICE: f_leak => my first novel
+NOTICE: f_leak => my second novel
+NOTICE: f_leak => my science fiction
+NOTICE: f_leak => great science fiction
+NOTICE: f_leak => great technology book
+NOTICE: f_leak => awesome science fiction
+NOTICE: f_leak => awesome technology book
+ did | cid | dlevel | dauthor | dtitle
+-----+-----+--------+-------------------+-------------------------
+ 1 | 11 | 1 | regress_rls_bob | my first novel
+ 2 | 11 | 2 | regress_rls_bob | my second novel
+ 3 | 22 | 2 | regress_rls_bob | my science fiction
+ 6 | 22 | 1 | regress_rls_carol | great science fiction
+ 7 | 33 | 2 | regress_rls_carol | great technology book
+ 9 | 22 | 1 | regress_rls_dave | awesome science fiction
+ 10 | 33 | 2 | regress_rls_dave | awesome technology book
+(7 rows)
+
+SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER BY did;
+NOTICE: f_leak => my first novel
+NOTICE: f_leak => my second novel
+NOTICE: f_leak => my science fiction
+NOTICE: f_leak => great science fiction
+NOTICE: f_leak => great technology book
+NOTICE: f_leak => awesome science fiction
+NOTICE: f_leak => awesome technology book
+ cid | did | dlevel | dauthor | dtitle | cname
+-----+-----+--------+-------------------+-------------------------+-----------------
+ 11 | 1 | 1 | regress_rls_bob | my first novel | novel
+ 11 | 2 | 2 | regress_rls_bob | my second novel | novel
+ 22 | 3 | 2 | regress_rls_bob | my science fiction | science fiction
+ 22 | 6 | 1 | regress_rls_carol | great science fiction | science fiction
+ 33 | 7 | 2 | regress_rls_carol | great technology book | technology
+ 22 | 9 | 1 | regress_rls_dave | awesome science fiction | science fiction
+ 33 | 10 | 2 | regress_rls_dave | awesome technology book | technology
+(7 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM document WHERE f_leak(dtitle);
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Subquery Scan on document
+ Filter: f_leak(document.dtitle)
+ -> Seq Scan on document document_1
+ Filter: ((cid <> 44) AND (cid <> 44) AND (cid < 50) AND (dlevel <= $0))
+ InitPlan 1 (returns $0)
+ -> Index Scan using uaccount_pkey on uaccount
+ Index Cond: (pguser = CURRENT_USER)
+(7 rows)
+
+EXPLAIN (COSTS OFF) SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Hash Join
+ Hash Cond: (category.cid = document.cid)
+ -> Seq Scan on category
+ -> Hash
+ -> Subquery Scan on document
+ Filter: f_leak(document.dtitle)
+ -> Seq Scan on document document_1
+ Filter: ((cid <> 44) AND (cid <> 44) AND (cid < 50) AND (dlevel <= $0))
+ InitPlan 1 (returns $0)
+ -> Index Scan using uaccount_pkey on uaccount
+ Index Cond: (pguser = CURRENT_USER)
+(11 rows)
+
+-- 44 would technically fail for both p2r and p1r, but we should get an error
+-- back from p1r for this because it sorts first
+INSERT INTO document VALUES (100, 44, 1, 'regress_rls_dave', 'testing sorting of policies'); -- fail
+ERROR: new row violates row-level security policy "p1r" for table "document"
+-- Just to see a p2r error
+INSERT INTO document VALUES (100, 55, 1, 'regress_rls_dave', 'testing sorting of policies'); -- fail
+ERROR: new row violates row-level security policy "p2r" for table "document"
-- only owner can change policies
ALTER POLICY p1 ON document USING (true); --fail
ERROR: must be owner of relation document
7 | 33 | 2 | regress_rls_carol | great technology book | |
(3 rows)
-INSERT INTO document VALUES (10, 33, 1, current_user, 'hoge');
+INSERT INTO document VALUES (11, 33, 1, current_user, 'hoge');
-- UNIQUE or PRIMARY KEY constraint violation DOES reveal presence of row
SET SESSION AUTHORIZATION regress_rls_bob;
INSERT INTO document VALUES (8, 44, 1, 'regress_rls_bob', 'my third manga'); -- Must fail with unique violation, revealing presence of did we can't see
RESET SESSION AUTHORIZATION;
SET row_security TO ON;
SELECT * FROM document;
- did | cid | dlevel | dauthor | dtitle
------+-----+--------+-------------------+-----------------------
+ did | cid | dlevel | dauthor | dtitle
+-----+-----+--------+-------------------+-------------------------
1 | 11 | 1 | regress_rls_bob | my first novel
2 | 11 | 2 | regress_rls_bob | my second novel
3 | 22 | 2 | regress_rls_bob | my science fiction
6 | 22 | 1 | regress_rls_carol | great science fiction
7 | 33 | 2 | regress_rls_carol | great technology book
8 | 44 | 1 | regress_rls_carol | great manga
- 10 | 33 | 1 | regress_rls_carol | hoge
-(9 rows)
+ 9 | 22 | 1 | regress_rls_dave | awesome science fiction
+ 10 | 33 | 2 | regress_rls_dave | awesome technology book
+ 11 | 33 | 1 | regress_rls_carol | hoge
+(11 rows)
SELECT * FROM category;
cid | cname
RESET SESSION AUTHORIZATION;
SET row_security TO OFF;
SELECT * FROM document;
- did | cid | dlevel | dauthor | dtitle
------+-----+--------+-------------------+-----------------------
+ did | cid | dlevel | dauthor | dtitle
+-----+-----+--------+-------------------+-------------------------
1 | 11 | 1 | regress_rls_bob | my first novel
2 | 11 | 2 | regress_rls_bob | my second novel
3 | 22 | 2 | regress_rls_bob | my science fiction
6 | 22 | 1 | regress_rls_carol | great science fiction
7 | 33 | 2 | regress_rls_carol | great technology book
8 | 44 | 1 | regress_rls_carol | great manga
- 10 | 33 | 1 | regress_rls_carol | hoge
-(9 rows)
+ 9 | 22 | 1 | regress_rls_dave | awesome science fiction
+ 10 | 33 | 2 | regress_rls_dave | awesome technology book
+ 11 | 33 | 1 | regress_rls_carol | hoge
+(11 rows)
SELECT * FROM category;
cid | cname
SET SESSION AUTHORIZATION regress_rls_exempt_user;
SET row_security TO OFF;
SELECT * FROM document;
- did | cid | dlevel | dauthor | dtitle
------+-----+--------+-------------------+-----------------------
+ did | cid | dlevel | dauthor | dtitle
+-----+-----+--------+-------------------+-------------------------
1 | 11 | 1 | regress_rls_bob | my first novel
2 | 11 | 2 | regress_rls_bob | my second novel
3 | 22 | 2 | regress_rls_bob | my science fiction
6 | 22 | 1 | regress_rls_carol | great science fiction
7 | 33 | 2 | regress_rls_carol | great technology book
8 | 44 | 1 | regress_rls_carol | great manga
- 10 | 33 | 1 | regress_rls_carol | hoge
-(9 rows)
+ 9 | 22 | 1 | regress_rls_dave | awesome science fiction
+ 10 | 33 | 2 | regress_rls_dave | awesome technology book
+ 11 | 33 | 1 | regress_rls_carol | hoge
+(11 rows)
SELECT * FROM category;
cid | cname
SET SESSION AUTHORIZATION regress_rls_alice;
SET row_security TO ON;
SELECT * FROM document;
- did | cid | dlevel | dauthor | dtitle
------+-----+--------+-------------------+-----------------------
+ did | cid | dlevel | dauthor | dtitle
+-----+-----+--------+-------------------+-------------------------
1 | 11 | 1 | regress_rls_bob | my first novel
2 | 11 | 2 | regress_rls_bob | my second novel
3 | 22 | 2 | regress_rls_bob | my science fiction
6 | 22 | 1 | regress_rls_carol | great science fiction
7 | 33 | 2 | regress_rls_carol | great technology book
8 | 44 | 1 | regress_rls_carol | great manga
- 10 | 33 | 1 | regress_rls_carol | hoge
-(9 rows)
+ 9 | 22 | 1 | regress_rls_dave | awesome science fiction
+ 10 | 33 | 2 | regress_rls_dave | awesome technology book
+ 11 | 33 | 1 | regress_rls_carol | hoge
+(11 rows)
SELECT * FROM category;
cid | cname
SET SESSION AUTHORIZATION regress_rls_alice;
SET row_security TO OFF;
SELECT * FROM document;
- did | cid | dlevel | dauthor | dtitle
------+-----+--------+-------------------+-----------------------
+ did | cid | dlevel | dauthor | dtitle
+-----+-----+--------+-------------------+-------------------------
1 | 11 | 1 | regress_rls_bob | my first novel
2 | 11 | 2 | regress_rls_bob | my second novel
3 | 22 | 2 | regress_rls_bob | my science fiction
6 | 22 | 1 | regress_rls_carol | great science fiction
7 | 33 | 2 | regress_rls_carol | great technology book
8 | 44 | 1 | regress_rls_carol | great manga
- 10 | 33 | 1 | regress_rls_carol | hoge
-(9 rows)
+ 9 | 22 | 1 | regress_rls_dave | awesome science fiction
+ 10 | 33 | 2 | regress_rls_dave | awesome technology book
+ 11 | 33 | 1 | regress_rls_carol | hoge
+(11 rows)
SELECT * FROM category;
cid | cname
--
SET SESSION AUTHORIZATION regress_rls_alice;
DROP POLICY p1 ON document;
+DROP POLICY p1r ON document;
CREATE POLICY p1 ON document FOR SELECT USING (true);
CREATE POLICY p2 ON document FOR INSERT WITH CHECK (dauthor = current_user);
CREATE POLICY p3 ON document FOR UPDATE
DROP USER regress_rls_alice;
DROP USER regress_rls_bob;
DROP USER regress_rls_carol;
+DROP USER regress_rls_dave;
DROP USER regress_rls_exempt_user;
DROP ROLE regress_rls_group1;
DROP ROLE regress_rls_group2;
pg_policies| SELECT n.nspname AS schemaname,
c.relname AS tablename,
pol.polname AS policyname,
+ CASE
+ WHEN pol.polpermissive THEN 'PERMISSIVE'::text
+ ELSE 'RESTRICTIVE'::text
+ END AS permissive,
CASE
WHEN (pol.polroles = '{0}'::oid[]) THEN (string_to_array('public'::text, ''::text))::name[]
ELSE ARRAY( SELECT pg_authid.rolname
DROP USER IF EXISTS regress_rls_alice;
DROP USER IF EXISTS regress_rls_bob;
DROP USER IF EXISTS regress_rls_carol;
+DROP USER IF EXISTS regress_rls_dave;
DROP USER IF EXISTS regress_rls_exempt_user;
DROP ROLE IF EXISTS regress_rls_group1;
DROP ROLE IF EXISTS regress_rls_group2;
CREATE USER regress_rls_alice NOLOGIN;
CREATE USER regress_rls_bob NOLOGIN;
CREATE USER regress_rls_carol NOLOGIN;
+CREATE USER regress_rls_dave NOLOGIN;
CREATE USER regress_rls_exempt_user BYPASSRLS NOLOGIN;
CREATE ROLE regress_rls_group1 NOLOGIN;
CREATE ROLE regress_rls_group2 NOLOGIN;
( 5, 44, 2, 'regress_rls_bob', 'my second manga'),
( 6, 22, 1, 'regress_rls_carol', 'great science fiction'),
( 7, 33, 2, 'regress_rls_carol', 'great technology book'),
- ( 8, 44, 1, 'regress_rls_carol', 'great manga');
+ ( 8, 44, 1, 'regress_rls_carol', 'great manga'),
+ ( 9, 22, 1, 'regress_rls_dave', 'awesome science fiction'),
+ (10, 33, 2, 'regress_rls_dave', 'awesome technology book');
ALTER TABLE document ENABLE ROW LEVEL SECURITY;
-- user's security level must be higher than or equal to document's
-CREATE POLICY p1 ON document
+CREATE POLICY p1 ON document AS PERMISSIVE
USING (dlevel <= (SELECT seclv FROM uaccount WHERE pguser = current_user));
+-- try to create a policy of bogus type
+CREATE POLICY p1 ON document AS UGLY
+ USING (dlevel <= (SELECT seclv FROM uaccount WHERE pguser = current_user));
+
+-- but Dave isn't allowed to anything at cid 50 or above
+-- this is to make sure that we sort the policies by name first
+-- when applying WITH CHECK, a later INSERT by Dave should fail due
+-- to p1r first
+CREATE POLICY p2r ON document AS RESTRICTIVE TO regress_rls_dave
+ USING (cid <> 44 AND cid < 50);
+
+-- and Dave isn't allowed to see manga documents
+CREATE POLICY p1r ON document AS RESTRICTIVE TO regress_rls_dave
+ USING (cid <> 44);
+
+\dp
+\d document
+SELECT * FROM pg_policies WHERE schemaname = 'regress_rls_schema' AND tablename = 'document' ORDER BY policyname;
+
-- viewpoint from regress_rls_bob
SET SESSION AUTHORIZATION regress_rls_bob;
SET row_security TO ON;
EXPLAIN (COSTS OFF) SELECT * FROM document WHERE f_leak(dtitle);
EXPLAIN (COSTS OFF) SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle);
+-- viewpoint from regress_rls_dave
+SET SESSION AUTHORIZATION regress_rls_dave;
+SELECT * FROM document WHERE f_leak(dtitle) ORDER BY did;
+SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER BY did;
+
+EXPLAIN (COSTS OFF) SELECT * FROM document WHERE f_leak(dtitle);
+EXPLAIN (COSTS OFF) SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle);
+
+-- 44 would technically fail for both p2r and p1r, but we should get an error
+-- back from p1r for this because it sorts first
+INSERT INTO document VALUES (100, 44, 1, 'regress_rls_dave', 'testing sorting of policies'); -- fail
+-- Just to see a p2r error
+INSERT INTO document VALUES (100, 55, 1, 'regress_rls_dave', 'testing sorting of policies'); -- fail
+
-- only owner can change policies
ALTER POLICY p1 ON document USING (true); --fail
DROP POLICY p1 ON document; --fail
-- can insert FK referencing invisible PK
SET SESSION AUTHORIZATION regress_rls_carol;
SELECT * FROM document d FULL OUTER JOIN category c on d.cid = c.cid;
-INSERT INTO document VALUES (10, 33, 1, current_user, 'hoge');
+INSERT INTO document VALUES (11, 33, 1, current_user, 'hoge');
-- UNIQUE or PRIMARY KEY constraint violation DOES reveal presence of row
SET SESSION AUTHORIZATION regress_rls_bob;
SET SESSION AUTHORIZATION regress_rls_alice;
DROP POLICY p1 ON document;
+DROP POLICY p1r ON document;
CREATE POLICY p1 ON document FOR SELECT USING (true);
CREATE POLICY p2 ON document FOR INSERT WITH CHECK (dauthor = current_user);
DROP USER regress_rls_alice;
DROP USER regress_rls_bob;
DROP USER regress_rls_carol;
+DROP USER regress_rls_dave;
DROP USER regress_rls_exempt_user;
DROP ROLE regress_rls_group1;
DROP ROLE regress_rls_group2;