]> granicus.if.org Git - postgresql/commitdiff
Add support for restrictive RLS policies
authorStephen Frost <sfrost@snowman.net>
Mon, 5 Dec 2016 20:50:55 +0000 (15:50 -0500)
committerStephen Frost <sfrost@snowman.net>
Mon, 5 Dec 2016 20:50:55 +0000 (15:50 -0500)
We have had support for restrictive RLS policies since 9.5, but they
were only available through extensions which use the appropriate hooks.
This adds support into the grammer, catalog, psql and pg_dump for
restrictive RLS policies, thus reducing the cases where an extension is
necessary.

In passing, also move away from using "AND"d and "OR"d in comments.
As pointed out by Alvaro, it's not really appropriate to attempt
to make verbs out of "AND" and "OR", so reword those comments which
attempted to.

Reviewed By: Jeevan Chalke, Dean Rasheed
Discussion: https://postgr.es/m/20160901063404.GY4028@tamriel.snowman.net

21 files changed:
doc/src/sgml/catalogs.sgml
doc/src/sgml/ddl.sgml
doc/src/sgml/ref/alter_policy.sgml
doc/src/sgml/ref/create_policy.sgml
src/backend/catalog/system_views.sql
src/backend/commands/policy.c
src/backend/nodes/copyfuncs.c
src/backend/nodes/equalfuncs.c
src/backend/parser/gram.y
src/backend/rewrite/rowsecurity.c
src/bin/pg_dump/pg_dump.c
src/bin/pg_dump/pg_dump.h
src/bin/pg_dump/t/002_pg_dump.pl
src/bin/psql/describe.c
src/bin/psql/tab-complete.c
src/include/catalog/pg_policy.h
src/include/nodes/parsenodes.h
src/include/rewrite/rowsecurity.h
src/test/regress/expected/rowsecurity.out
src/test/regress/expected/rules.out
src/test/regress/sql/rowsecurity.sql

index 561e228558d8fda5c17f8d66ab59532ac6b00120..c4246dcd866e07be2304c0572b6f461feae20dcf 100644 (file)
        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>
@@ -8437,6 +8444,12 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
       <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>
index 157512c7abddab710d1307769014e99b5f6d1399..7e1bc0e5341ebab755885c98d150adeee0bdf60f 100644 (file)
@@ -1599,9 +1599,11 @@ REVOKE ALL ON accounts FROM PUBLIC;
 
   <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>
@@ -1761,6 +1763,56 @@ ERROR:  permission denied for relation passwd
 -- Alice can change her own password; RLS silently prevents updating other rows
 postgres=&gt; 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>
+=&gt; SELECT current_user;
+ current_user 
+--------------
+ admin
+(1 row)
+
+=&gt; select inet_client_addr();
+ inet_client_addr 
+------------------
+ 127.0.0.1
+(1 row)
+
+=&gt; SELECT current_user;
+ current_user 
+--------------
+ admin
+(1 row)
+
+=&gt; TABLE passwd;
+ user_name | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell
+-----------+--------+-----+-----+-----------+------------+------------+----------+-------
+(0 rows)
+
+=&gt; UPDATE passwd set pwhash = NULL;
+UPDATE 0
 </programlisting>
 
   <para>
index a9b1541322df615f913de2d97811265cc738c832..df347d180ea686050fbaa108a224c3e1642b658d 100644 (file)
@@ -35,7 +35,12 @@ ALTER POLICY <replaceable class="parameter">name</replaceable> ON <replaceable c
 
   <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>
index 89d27879b1e30e1cb380cbb9ccecde4f4b67b088..f0486effaf5c76d107e4e490ffb86bbb516f8079 100644 (file)
@@ -22,6 +22,7 @@ PostgreSQL documentation
  <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> ) ]
@@ -119,6 +120,33 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <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>
@@ -390,6 +418,16 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
    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,
index e011af122c5bec0d6bc6cd52e6b6fa4932ef189e..df59d1819caa0acdb43717b576b8e71cbb8eff7e 100644 (file)
@@ -75,6 +75,12 @@ CREATE VIEW pg_policies AS
         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', '')
index d694cf80be3a1c109ecf1d48b893b19ed8d4a1d7..70e22c100001b776594e404bdcd3df7217716e38 100644 (file)
@@ -235,6 +235,7 @@ RelationBuildRowSecurity(Relation relation)
                {
                        Datum           value_datum;
                        char            cmd_value;
+                       bool            permissive_value;
                        Datum           roles_datum;
                        char       *qual_value;
                        Expr       *qual_expr;
@@ -257,6 +258,12 @@ RelationBuildRowSecurity(Relation relation)
                        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);
@@ -298,6 +305,7 @@ RelationBuildRowSecurity(Relation relation)
                        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);
@@ -796,6 +804,7 @@ CreatePolicy(CreatePolicyStmt *stmt)
        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. */
index 04e49b77951d835da788db1aa52691831a7b40e4..dd66adb0b24b9ce6b7bed2f7b25c5058b6d53568 100644 (file)
@@ -4166,6 +4166,7 @@ _copyCreatePolicyStmt(const CreatePolicyStmt *from)
        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);
index 2eaf41c37f896a1affda3f1dc579abf00d9c0571..cad3aebecd53940c5529da45eff4cec656714071 100644 (file)
@@ -2125,6 +2125,7 @@ _equalCreatePolicyStmt(const CreatePolicyStmt *a, const CreatePolicyStmt *b)
        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);
index d6274b49e7fd85d3566b9f8a8f6638a12f2087af..414348b95b4b1be78820e3ae48c3bc591482bb3e 100644 (file)
@@ -332,6 +332,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <str>            all_Op MathOp
 
 %type <str>            row_security_cmd RowSecurityDefaultForCmd
+%type <boolean> RowSecurityDefaultPermissive
 %type <node>   RowSecurityOptionalWithCheck RowSecurityOptionalExpr
 %type <list>   RowSecurityDefaultToRole RowSecurityOptionalToRole
 
@@ -4628,26 +4629,30 @@ AlterUserMappingStmt: ALTER USER MAPPING FOR auth_ident SERVER name alter_generi
 /*****************************************************************************
  *
  *             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;
                                }
                ;
@@ -4711,6 +4716,24 @@ RowSecurityOptionalToRole:
                        | /* 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"; }
index e02911656a3f29714ff119393e1f6433f65274c6..b7edefc7ddfdd8caacfb7956e99965db67cc1f2f 100644 (file)
@@ -86,10 +86,10 @@ static bool check_role_for_policy(ArrayType *policy_roles, Oid user_id);
  * 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;
@@ -212,8 +212,8 @@ get_row_security_policies(Query *root, RangeTblEntry *rte, int rt_index,
        /*
         * 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,
@@ -433,9 +433,20 @@ get_policies_for_relation(Relation relation, CmdType cmd, Oid user_id,
                 * 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
@@ -447,8 +458,10 @@ get_policies_for_relation(Relation relation, CmdType cmd, Oid user_id,
                (*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);
 
@@ -481,8 +494,8 @@ get_policies_for_relation(Relation relation, CmdType cmd, Oid user_id,
  *
  * 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)
@@ -580,8 +593,8 @@ add_security_quals(int rt_index,
                /*
                 * 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)
                {
@@ -599,8 +612,8 @@ add_security_quals(int rt_index,
                }
 
                /*
-                * 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);
@@ -681,10 +694,11 @@ add_with_check_options(Relation rel,
        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;
 
@@ -705,9 +719,9 @@ add_with_check_options(Relation rel,
 
                /*
                 * 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)
                {
index 2ff60b9879670a9ab4e6a065581e4fe8fc9adaa2..42873bb32ac918539c04afd0f89179991e330df8 100644 (file)
@@ -3037,6 +3037,7 @@ getPolicies(Archive *fout, TableInfo tblinfo[], int numTables)
        int                     i_tableoid;
        int                     i_polname;
        int                     i_polcmd;
+       int                     i_polpermissive;
        int                     i_polroles;
        int                     i_polqual;
        int                     i_polwithcheck;
@@ -3082,7 +3083,8 @@ getPolicies(Archive *fout, TableInfo tblinfo[], int numTables)
                        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;
@@ -3101,15 +3103,26 @@ getPolicies(Archive *fout, TableInfo tblinfo[], int numTables)
                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);
@@ -3129,6 +3142,7 @@ getPolicies(Archive *fout, TableInfo tblinfo[], int numTables)
                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");
@@ -3147,8 +3161,13 @@ getPolicies(Archive *fout, TableInfo tblinfo[], int numTables)
                        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;
@@ -3210,19 +3229,19 @@ dumpPolicy(Archive *fout, PolicyInfo *polinfo)
                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);
        }
@@ -3231,7 +3250,9 @@ dumpPolicy(Archive *fout, PolicyInfo *polinfo)
        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);
index f3e597717834966a5285c2769f3abc0c1a966721..7df9066cd75cdc1a74030a97a22118194603160b 100644 (file)
@@ -547,7 +547,8 @@ typedef struct _policyInfo
        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;
index 7379487471cd99537baad0f5edbf99e43f5caf23..f8955228cf77534c9fe042fea7580fcbea23e334 100644 (file)
@@ -2004,7 +2004,7 @@ my %tests = (
                                                   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 => {
@@ -2166,7 +2166,36 @@ my %tests = (
                        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',
index 16321045980bedc016eefbe66f23f03c68ec4e3a..931c6887f958089c636ea8b13a8b78679ddc5c5f 100644 (file)
@@ -887,10 +887,44 @@ permissionsList(const char *pattern)
                                                  "  ), 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"
@@ -2112,21 +2146,36 @@ describeOneTableDetails(const char *schemaname,
                /* 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)
@@ -2160,23 +2209,26 @@ describeOneTableDetails(const char *schemaname,
                                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);
 
index 6aa3f20e1377efb8d4e50bc49a9e8b27841ba82a..6b95052a6726d581cfb157c97471e816663f258c 100644 (file)
@@ -2162,9 +2162,15 @@ psql_completion(const char *text, int start, int end)
        /* 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");
@@ -2183,6 +2189,25 @@ psql_completion(const char *text, int start, int end)
        /* 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" */
index d73e9c2c1ac479ee2fd5d322dc69d098dbb35517..67b5fb5cd26edea2edf74946d377b3d4544fbc49 100644 (file)
@@ -23,6 +23,7 @@ CATALOG(pg_policy,3256)
        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 */
@@ -42,12 +43,13 @@ typedef FormData_pg_policy *Form_pg_policy;
  *             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 */
index 04b1c2f2d436eddf94c64e2ef52135feb773b81f..f8003e46f3a00bce283313844895c412296323b0 100644 (file)
@@ -2077,6 +2077,7 @@ typedef struct CreatePolicyStmt
        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. */
index fd0cbaff5967fc1d06642b03e1cd043fcc95f86b..2f3db8cf415b8d05addb92e70ea4e33282856041 100644 (file)
@@ -22,6 +22,7 @@ typedef struct RowSecurityPolicy
        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 */
index abfee92f4de0402cb630d703f369ea83d79f0ae6..471e405c7ab43702135c673ef5c0eb5042015ec7 100644 (file)
@@ -7,6 +7,7 @@ SET client_min_messages TO 'warning';
 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;
@@ -16,6 +17,7 @@ RESET client_min_messages;
 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;
@@ -67,11 +69,84 @@ INSERT INTO document VALUES
     ( 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;
@@ -80,26 +155,30 @@ NOTICE:  f_leak => my first novel
 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)
@@ -107,12 +186,14 @@ 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;
@@ -125,8 +206,10 @@ NOTICE:  f_leak => my second manga
 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
@@ -135,7 +218,9 @@ NOTICE:  f_leak => great 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 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
@@ -146,17 +231,21 @@ NOTICE:  f_leak => my second manga
 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)
@@ -165,13 +254,15 @@ NOTICE:  f_leak => my first manga
 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                        
@@ -201,6 +292,81 @@ EXPLAIN (COSTS OFF) SELECT * FROM document NATURAL JOIN category WHERE f_leak(dt
                              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
@@ -318,7 +484,7 @@ SELECT * FROM document d FULL OUTER JOIN category c on d.cid = c.cid;
    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
@@ -337,8 +503,8 @@ ERROR:  new row violates row-level security policy for table "document"
 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
@@ -347,8 +513,10 @@ SELECT * FROM document;
    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      
@@ -363,8 +531,8 @@ SELECT * FROM category;
 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
@@ -373,8 +541,10 @@ SELECT * FROM document;
    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      
@@ -389,8 +559,8 @@ SELECT * FROM category;
 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
@@ -399,8 +569,10 @@ SELECT * FROM document;
    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      
@@ -415,8 +587,8 @@ SELECT * FROM category;
 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
@@ -425,8 +597,10 @@ SELECT * FROM document;
    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      
@@ -441,8 +615,8 @@ SELECT * FROM category;
 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
@@ -451,8 +625,10 @@ SELECT * FROM document;
    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      
@@ -1517,6 +1693,7 @@ SELECT * FROM b1;
 --
 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
@@ -3461,6 +3638,7 @@ RESET client_min_messages;
 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;
index 031e8c2ef5307500adcbdcdafc910f38fa77ca70..a8f35a76fabdb10424f262d917f3643e8063daa6 100644 (file)
@@ -1379,6 +1379,10 @@ pg_matviews| SELECT n.nspname AS schemaname,
 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
index 7fcefe45026f665ce7e2d68ba83b15155188b461..5e2f4ef88487860f763d7bdddb07840f45a1eb2e 100644 (file)
@@ -10,6 +10,7 @@ SET client_min_messages TO 'warning';
 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;
@@ -22,6 +23,7 @@ RESET client_min_messages;
 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;
@@ -80,14 +82,35 @@ INSERT INTO document VALUES
     ( 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;
@@ -110,6 +133,20 @@ SELECT * FROM document TABLESAMPLE BERNOULLI(50) REPEATABLE(0)
 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
@@ -147,7 +184,7 @@ DELETE FROM category WHERE cid = 33;    -- fails with FK violation
 -- 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;
@@ -517,6 +554,7 @@ SELECT * FROM b1;
 
 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);
@@ -1577,6 +1615,7 @@ RESET client_min_messages;
 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;