Do some copy-editing on the docs for row-level security.

Clarifications, markup improvements, corrections of misleading or
outright wrong statements.
This commit is contained in:
Tom Lane 2016-01-03 20:04:11 -05:00
parent 939d10cd87
commit c1611db01f
4 changed files with 234 additions and 193 deletions

View File

@ -1512,7 +1512,7 @@ REVOKE ALL ON accounts FROM PUBLIC;
<title>Row Security Policies</title>
<indexterm zone="ddl-rowsecurity">
<primary>row security</primary>
<primary>row-level security</primary>
</indexterm>
<indexterm zone="ddl-rowsecurity">
@ -1520,54 +1520,68 @@ REVOKE ALL ON accounts FROM PUBLIC;
</indexterm>
<para>
In addition to the <xref linkend="ddl-priv"> system available through
<xref linkend="sql-grant">, tables can have row security policies
which limit the rows returned for normal queries and rows which can
be added through data modification commands. By default, tables do
not have any policies and all rows are visible and able to be added,
subject to the regular <xref linkend="ddl-priv"> system. This is
also known as Row Level Security.
In addition to the SQL-standard <link linkend="ddl-priv">privilege
system</link> available through <xref linkend="sql-grant">,
tables can have <firstterm>row security policies</> that restrict,
on a per-user basis, which rows can be returned by normal queries
or inserted, updated, or deleted by data modification commands.
This feature is also known as <firstterm>Row-Level Security</>.
By default, tables do not have any policies, so that if a user has
access privileges to a table according to the SQL privilege system,
all rows within it are equally available for querying or updating.
</para>
<para>
When row security is enabled on a table with
<xref linkend="sql-altertable">, all normal access to the table
(excluding the owner) for selecting rows or adding rows must be through
a policy. If no policy exists for the table, a default-deny policy is
used and no rows are visible or can be added. Privileges which operate
at the whole table level such as <literal>TRUNCATE</>, and
<literal>REFERENCES</> are not subject to row security.
When row security is enabled on a table (with
<link linkend="sql-altertable">ALTER TABLE ... ENABLE ROW LEVEL
SECURITY</>), all normal access to the table for selecting rows or
modifying rows must be allowed by a row security policy. (However, the
table's owner is typically not subject to row security policies.) If no
policy exists for the table, a default-deny policy is used, meaning that
no rows are visible or can be modified. Operations that apply to the
whole table, such as <command>TRUNCATE</> and <literal>REFERENCES</>,
are not subject to row security.
</para>
<para>
Row security policies can be specific to commands, or to roles, or to
both. The commands available are <literal>ALL</literal>,
<literal>SELECT</>, <literal>INSERT</>, <literal>UPDATE</>, and
<literal>DELETE</>. Multiple roles can be assigned to a given policy and
normal role membership and inheritance rules apply. Table owners,
superusers, and roles with the <literal>BYPASSRLS</> attribute bypass the
row security system when querying a table. Applications that expect to
bypass all row security through those mechanisms should
set <xref linkend="guc-row-security"> to <literal>off</>.
both. A policy can be specified to apply to <literal>ALL</literal>
commands, or to <literal>SELECT</>, <literal>INSERT</>, <literal>UPDATE</>,
or <literal>DELETE</>. Multiple roles can be assigned to a given
policy, and normal role membership and inheritance rules apply.
</para>
<para>
To specify which rows are visible and what rows can be added to the
table with row level security, an expression is required which returns
a Boolean result. This expression will be evaluated for each row prior
to other conditionals or functions which are part of the query. The
one exception to this rule are <literal>leakproof</literal> functions,
which are guaranteed to not leak information. Two expressions may be
specified to provide independent control over the rows which are
visible and the rows which are allowed to be added. The expression
is run as part of the query and with the privileges of the user
running the query, however, security definer functions can be used in
the expression.
To specify which rows are visible or modifiable according to a policy,
an expression is required that returns a Boolean result. This
expression will be evaluated for each row prior to any conditions or
functions coming from the user's query. (The only exceptions to this
rule are <literal>leakproof</literal> functions, which are guaranteed to
not leak information; the optimizer may choose to apply such functions
ahead of the row-security check.) Rows for which the expression does
not return <literal>true</> will not be processed. Separate expressions
may be specified to provide independent control over the rows which are
visible and the rows which are allowed to be modified. Policy
expressions are run as part of the query and with the privileges of the
user running the query, although security-definer functions can be used
to access data not available to the calling user.
</para>
<para>
Superusers and roles with the <literal>BYPASSRLS</> attribute always
bypass the row security system when accessing a table. Table owners
normally bypass row security as well, though a table owner can choose to
be subject to row security with <link linkend="sql-altertable">ALTER
TABLE ... FORCE ROW LEVEL SECURITY</>. Even in a table with that option
selected, the table owner will bypass row security if the
<xref linkend="guc-row-security"> configuration parameter is set
to <literal>off</>; this setting is typically used for purposes such as
backup and restore.
</para>
<para>
Enabling and disabling row security, as well as adding policies to a
table, is always the privilege of the owner only.
table, is always the privilege of the table owner only.
</para>
<para>
@ -1587,46 +1601,40 @@ REVOKE ALL ON accounts FROM PUBLIC;
<para>
When multiple policies apply to a given query, they are combined using
<literal>OR</literal>, similar to how a given role has the privileges
of all roles which they are a member of.
<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.
</para>
<para>
Referential integrity checks, such as unique or primary key constraints
and foreign key references, will bypass row security to ensure that
and foreign key references, always bypass row security to ensure that
data integrity is maintained. Care must be taken when developing
schemas and row level policies to avoid a "covert channel" leak of
information through these referential integrity checks.
schemas and row level policies to avoid <quote>covert channel</> leaks of
information through such referential integrity checks.
</para>
<para>
To enable row security for a table,
the <command>ALTER TABLE</command> is used. For example, to enable
row level security for the table accounts, use:
As a simple example, here is how to create a policy on
the <literal>account</> relation to allow only members of
the <literal>managers</> role to access rows, and only rows of their
accounts:
</para>
<programlisting>
-- Create the table first
CREATE TABLE accounts (manager text, company text, contact_email text);
ALTER TABLE accounts ENABLE ROW LEVEL SECURITY;
</programlisting>
<para>
To create a policy on the account relation to allow the managers role
to view the rows of their accounts, the <command>CREATE POLICY</command>
command can be used:
</para>
<programlisting>
CREATE POLICY account_managers ON accounts TO managers
USING (manager = current_user);
</programlisting>
<para>
If no role is specified, or the special <quote>user</quote> name
If no role is specified, or the special user name
<literal>PUBLIC</literal> is used, then the policy applies to all
users on the system. To allow all users to view their own row in
a user table, a simple policy can be used:
users on the system. To allow all users to access their own row in
a <literal>users</> table, a simple policy can be used:
</para>
<programlisting>
@ -1635,10 +1643,10 @@ CREATE POLICY user_policy ON users
</programlisting>
<para>
To use a different policy for rows which are being added to the
table from those rows which are visible, the WITH CHECK clause
can be used. This would allow all users to view all rows in the
users table, but only modify their own:
To use a different policy for rows that are being added to the table
compared to those rows that are visible, the <literal>WITH CHECK</>
clause can be used. This policy would allow all users to view all rows
in the <literal>users</> table, but only modify their own:
</para>
<programlisting>
@ -1648,16 +1656,17 @@ CREATE POLICY user_policy ON users
</programlisting>
<para>
Row security can be disabled with the <command>ALTER TABLE</command>
also. Note that disabling row security does not remove the
policies which are defined on the table, they are simply ignored
and all rows are visible and able to be added, subject to the
normal privileges system.
Row security can also be disabled with the <command>ALTER TABLE</>
command. Disabling row security does not remove any policies that are
defined on the table; they are simply ignored. Then all rows in the
table are visible and modifiable, subject to the standard SQL privileges
system.
</para>
<para>
Below is a larger example of how this feature can be used in
production environments, based on a Unix password file.
Below is a larger example of how this feature can be used in production
environments. The table <literal>passwd</> emulates a Unix password
file:
</para>
<programlisting>
@ -1726,7 +1735,7 @@ GRANT UPDATE
postgres=&gt; set role admin;
SET
postgres=&gt; table passwd;
username | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell
username | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell
----------+--------+-----+-----+-----------+--------------+------------+-------------+-----------
admin | xxx | 0 | 0 | Admin | 111-222-3333 | | /root | /bin/dash
bob | xxx | 1 | 1 | Bob | 123-456-7890 | | /home/bob | /bin/zsh
@ -1739,7 +1748,7 @@ SET
postgres=&gt; table passwd;
ERROR: permission denied for relation passwd
postgres=&gt; select username,real_name,home_phone,extra_info,home_dir,shell from passwd;
username | real_name | home_phone | extra_info | home_dir | shell
username | real_name | home_phone | extra_info | home_dir | shell
----------+-----------+--------------+------------+-------------+-----------
admin | Admin | 111-222-3333 | | /root | /bin/dash
bob | Bob | 123-456-7890 | | /home/bob | /bin/zsh
@ -1748,7 +1757,7 @@ postgres=&gt; select username,real_name,home_phone,extra_info,home_dir,shell fro
postgres=&gt; update passwd set username = 'joe';
ERROR: permission denied for relation passwd
-- Allowed to change her own real_name, but no others
-- Alice is allowed to change her own real_name, but no others
postgres=&gt; update passwd set real_name = 'Alice Doe';
UPDATE 1
postgres=&gt; update passwd set real_name = 'John Doe' where username = 'admin';
@ -1759,11 +1768,16 @@ postgres=&gt; delete from passwd;
ERROR: permission denied for relation passwd
postgres=&gt; insert into passwd (username) values ('xxx');
ERROR: permission denied for relation passwd
-- Alice can change her own password
-- Alice can change her own password; RLS silently prevents updating other rows
postgres=&gt; update passwd set pwhash = 'abc';
UPDATE 1
</programlisting>
<para>
For additional details see <xref linkend="sql-createpolicy">
and <xref linkend="sql-altertable">.
</para>
</sect1>
<sect1 id="ddl-schemas">

View File

@ -16,13 +16,14 @@ PostgreSQL documentation
<refnamediv>
<refname>ALTER POLICY</refname>
<refpurpose>change the definition of a policy</refpurpose>
<refpurpose>change the definition of a row level security policy</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
ALTER POLICY <replaceable class="parameter">name</replaceable> ON <replaceable class="parameter">table_name</replaceable> RENAME TO <replaceable class="PARAMETER">new_name</replaceable>
ALTER POLICY <replaceable class="parameter">name</replaceable> ON <replaceable class="parameter">table_name</replaceable>
[ RENAME TO <replaceable class="PARAMETER">new_name</replaceable> ]
[ TO { <replaceable class="parameter">role_name</replaceable> | PUBLIC | CURRENT_USER | SESSION_USER } [, ...] ]
[ USING ( <replaceable class="parameter">using_expression</replaceable> ) ]
[ WITH CHECK ( <replaceable class="parameter">check_expression</replaceable> ) ]
@ -33,14 +34,22 @@ ALTER POLICY <replaceable class="parameter">name</replaceable> ON <replaceable c
<title>Description</title>
<para>
<command>ALTER POLICY</command> changes the <replaceable class="parameter">
definition</replaceable> of an existing policy.
<command>ALTER POLICY</command> changes the definition of an existing
row-level security policy.
</para>
<para>
To use <command>ALTER POLICY</command>, you must own the table that
the policy applies to.
</para>
<para>
In the second form of <command>ALTER POLICY</command>, the role list,
<replaceable class="parameter">using_expression</replaceable>, and
<replaceable class="parameter">check_expression</replaceable> are replaced
independently if specified. When one of those clauses is omitted, the
corresponding part of the policy is unchanged.
</para>
</refsect1>
<refsect1>
@ -79,9 +88,9 @@ ALTER POLICY <replaceable class="parameter">name</replaceable> ON <replaceable c
<term><replaceable class="parameter">role_name</replaceable></term>
<listitem>
<para>
The role to which the policy applies. Multiple roles can be specified at one time.
To apply the policy to all roles, use <literal>PUBLIC</literal>, which is also
the default.
The role(s) to which the policy applies. Multiple roles can be
specified at one time. To apply the policy to all roles,
use <literal>PUBLIC</literal>.
</para>
</listitem>
</varlistentry>

View File

@ -16,7 +16,7 @@ PostgreSQL documentation
<refnamediv>
<refname>CREATE POLICY</refname>
<refpurpose>define a new policy for a table</refpurpose>
<refpurpose>define a new row level security policy for a table</refpurpose>
</refnamediv>
<refsynopsisdiv>
@ -33,40 +33,34 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
<title>Description</title>
<para>
The <command>CREATE POLICY</command> command defines a new policy for a
table. Note that row-level security must also be enabled on the table using
<command>ALTER TABLE</command> in order for created policies to be applied.
The <command>CREATE POLICY</command> command defines a new row-level
security policy for a table. Note that row-level security must be
enabled on the table (using <command>ALTER TABLE ... ENABLE ROW LEVEL
SECURITY</command>) in order for created policies to be applied.
</para>
<para>
A policy grants the permission to select, insert, update, or delete rows
that match the relevant policy expression. Existing table rows are
checked against the expression specified via <literal>USING</literal>, while new rows that
would be created via <literal>INSERT</literal> or <literal>UPDATE</literal> are checked against the expression
specified via <literal>WITH CHECK</literal>. When a <literal>USING</literal> expression returns true for a given
row then that row is visible to the user, while if a false or null is
returned then the row is not visible. When a <literal>WITH CHECK</literal> expression
returns true for a row then that row is added, while if a false or null is
returned then an error occurs.
</para>
<para>
Generally, the system will enforce filter conditions imposed using
security policies prior to qualifications that appear in the query itself,
in order to prevent the inadvertent exposure of the protected data to
user-defined functions which might not be trustworthy. However,
functions and operators marked by the system (or the system
administrator) as <literal>LEAKPROOF</literal> may be evaluated before policy
expressions, as they are assumed to be trustworthy.
checked against the expression specified in <literal>USING</literal>,
while new rows that would be created via <literal>INSERT</literal>
or <literal>UPDATE</literal> are checked against the expression specified
in <literal>WITH CHECK</literal>. When a <literal>USING</literal>
expression returns true for a given row then that row is visible to the
user, while if false or null is returned then the row is not visible.
When a <literal>WITH CHECK</literal> expression returns true for a row
then that row is inserted or updated, while if false or null is returned
then an error occurs.
</para>
<para>
For <command>INSERT</command> and <command>UPDATE</command> statements,
<literal>WITH CHECK</literal> expressions are enforced after
<literal>BEFORE</literal> triggers are fired, and before any data modifications are made.
Thus a <literal>BEFORE ROW</literal> trigger may modify the data to be inserted, affecting
the result of the security policy check. <literal>WITH CHECK</literal> expressions are
enforced before any other constraints.
<literal>BEFORE</literal> triggers are fired, and before any actual data
modifications are made. Thus a <literal>BEFORE ROW</literal> trigger may
modify the data to be inserted, affecting the result of the security
policy check. <literal>WITH CHECK</literal> expressions are enforced
before any other constraints.
</para>
<para>
@ -79,18 +73,25 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
Policies can be applied for specific commands or for specific roles. The
default for newly created policies is that they apply for all commands and
roles, unless otherwise specified. If multiple policies apply to a given
statement, they will be combined using <quote>or</quote> (although <literal>ON CONFLICT DO
statement, they will be combined using OR (although <literal>ON CONFLICT DO
UPDATE</> and <literal>INSERT</> policies are not combined in this way, but
rather enforced as noted at each stage of <literal>ON CONFLICT</> execution).
</para>
<para>
Further, for commands that can have both <literal>USING</literal>
For commands that can have both <literal>USING</literal>
and <literal>WITH CHECK</literal> policies (<literal>ALL</literal>
and <literal>UPDATE</literal>), if no <literal>WITH CHECK</literal> policy
is defined, then the <literal>USING</literal> policy will be used for both
what rows are visible (normal <literal>USING</literal> case) and which rows
will be allowed to be added (<literal>WITH CHECK</literal> case).
and <literal>UPDATE</literal>), if no <literal>WITH CHECK</literal>
policy is defined, then the <literal>USING</literal> policy will be used
both for which rows are visible (normal <literal>USING</literal> case)
and for which rows will be allowed to be added (<literal>WITH
CHECK</literal> case).
</para>
<para>
If row-level security is enabled for a table, but no applicable policies
exist, a <quote>default deny</> policy is assumed, so that no rows will
be visible or updatable.
</para>
</refsect1>
@ -136,7 +137,7 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
<term><replaceable class="parameter">role_name</replaceable></term>
<listitem>
<para>
The roles to which the policy is to be applied. The default is
The role(s) to which the policy is to be applied. The default is
<literal>PUBLIC</literal>, which will apply the policy to all roles.
</para>
</listitem>
@ -149,10 +150,13 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
Any <acronym>SQL</acronym> conditional expression (returning
<type>boolean</type>). The conditional expression cannot contain
any aggregate or window functions. This expression will be added
to queries that refer to the table if row level security is enabled
and rows for which the expression returns true will be visible. Any
to queries that refer to the table if row level security is enabled.
Rows for which the expression returns true will be visible. Any
rows for which the expression returns false or null will not be
visible to the user.
visible to the user (in a <command>SELECT</>), and will not be
available for modification (in an <command>UPDATE</>
or <command>DELETE</>). Such rows are silently suppressed; no error
is reported.
</para>
</listitem>
</varlistentry>
@ -163,12 +167,15 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
<para>
Any <acronym>SQL</acronym> conditional expression (returning
<type>boolean</type>). The conditional expression cannot contain
any aggregate or window functions. This expression will be used with
any aggregate or window functions. This expression will be used in
<command>INSERT</command> and <command>UPDATE</command> queries against
the table if row level security is enabled and only rows where the
the table if row level security is enabled. Only rows for which the
expression evaluates to true will be allowed. An error will be thrown
if the expression evaluates to false or null for any of the records
inserted or any of the records that result from the update.
inserted or any of the records that result from the update. Note that
the <replaceable class="parameter">check_expression</replaceable> is
evaluated against the proposed new contents of the row, not the
original contents.
</para>
</listitem>
</varlistentry>
@ -176,7 +183,7 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
</variablelist>
<refsect2>
<title>Per-Command policies</title>
<title>Per-Command Policies</title>
<variablelist>
@ -189,25 +196,25 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
<literal>ALL</literal> policy exists and more specific policies
exist, then both the <literal>ALL</literal> policy and the more
specific policy (or policies) will be combined using
<quote>or</quote>, as usual for overlapping policies.
OR, as usual for overlapping policies.
Additionally, <literal>ALL</literal> policies will be applied to
both the selection side of a query and the modification side, using
the <literal>USING</literal> policy for both if only a <literal>USING</literal> policy has been defined.
the <literal>USING</literal> expression for both cases if only
a <literal>USING</literal> expression has been defined.
</para>
<para>
As an example, if an <literal>UPDATE</literal> is issued, then the
<literal>ALL</literal> policy will be applicable to both what the
<literal>UPDATE</literal> will be able to select out as rows to be
updated (with the <literal>USING</literal> expression being applied), and it will be
applied to rows that result from the <literal>UPDATE</literal>
statement, to check if they are permitted to be added to the table
(using the <literal>WITH CHECK</literal> expression, if defined, and the <literal>USING</literal> expression
otherwise). If an <command>INSERT</command> or <command>UPDATE</command> command attempts to add rows to
the table that do not pass the <literal>ALL</literal> <literal>WITH CHECK</literal>
expression, the entire command will be aborted. Note that if only a
<literal>USING</literal> clause is specified then that clause will be
used for both <literal>USING</literal> and
<literal>WITH CHECK</literal> cases.
<literal>ALL</literal> policy will be applicable both to what the
<literal>UPDATE</literal> will be able to select as rows to be
updated (applying the <literal>USING</literal> expression),
and to the resulting updated rows, to check if they are permitted
to be added to the table (applying the <literal>WITH CHECK</literal>
expression, if defined, and the <literal>USING</literal> expression
otherwise). If an <command>INSERT</command>
or <command>UPDATE</command> command attempts to add rows to the
table that do not pass the <literal>ALL</literal>
policy's <literal>WITH CHECK</literal> expression, the entire
command will be aborted.
</para>
</listitem>
</varlistentry>
@ -221,13 +228,12 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
<literal>SELECT</literal> permissions are required on the relation the
policy is defined for. The result is that only those records from the
relation that pass the <literal>SELECT</literal> policy will be
returned during a <literal>SELECT</literal> query, even if other
records exist in the relation and that queries which require
<literal>SELECT</literal> permissions, such as
returned during a <literal>SELECT</literal> query, and that queries
that require <literal>SELECT</literal> permissions, such as
<literal>UPDATE</literal>, will also only see those records
which are allowed by the <literal>SELECT</literal> policy.
The <literal>SELECT</literal> policy only accepts the
<literal>USING</literal> expression as it only applies in cases where
that are allowed by the <literal>SELECT</literal> policy.
A <literal>SELECT</literal> policy cannot have a <literal>WITH
CHECK</literal> expression, as it only applies in cases where
records are being retrieved from the relation.
</para>
</listitem>
@ -240,16 +246,16 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
Using <literal>INSERT</literal> for a policy means that it will apply
to <literal>INSERT</literal> commands. Rows being inserted that do
not pass this policy will result in a policy violation error, and the
entire <literal>INSERT</literal> command will be aborted. The
<literal>INSERT</literal> policy only accepts the
<literal>WITH CHECK</literal> expression as it only applies in cases
entire <literal>INSERT</literal> command will be aborted.
An <literal>INSERT</literal> policy cannot have
a <literal>USING</literal> expression, as it only applies in cases
where records are being added to the relation.
</para>
<para>
Note that <literal>INSERT</literal> with <literal>ON CONFLICT DO
UPDATE</literal> requires that any <literal>INSERT</literal> policy
<literal>WITH CHECK</literal> expression passes for any rows appended
to the relation by the <literal>INSERT</literal> path only.
UPDATE</literal> checks <literal>INSERT</literal> policies'
<literal>WITH CHECK</literal> expressions only for rows appended
to the relation by the <literal>INSERT</literal> path.
</para>
</listitem>
</varlistentry>
@ -261,19 +267,15 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
Using <literal>UPDATE</literal> for a policy means that it will apply
to <literal>UPDATE</literal> commands (or auxiliary <literal>ON
CONFLICT DO UPDATE</literal> clauses of <literal>INSERT</literal>
commands). As <literal>UPDATE</literal> involves pulling an existing
record and then making changes to some portion (but possibly not all)
of the record, the <literal>UPDATE</literal> policy accepts both a
<literal>USING</literal> expression and a <literal>WITH CHECK</literal>
expression.
</para>
<para>
The <literal>USING</literal> expression will be used to
determine which records the <literal>UPDATE</literal> command will see
to operate against, while the <literal>WITH CHECK</literal> expression
defines what rows are allowed to be added back into the relation
(similar to the <literal>INSERT</literal> policy).
commands). Since <literal>UPDATE</literal> involves pulling an
existing record and then making changes to some portion (but
possibly not all) of the record, <literal>UPDATE</literal>
policies accept both a <literal>USING</literal> expression and
a <literal>WITH CHECK</literal> expression.
The <literal>USING</literal> expression determines which records
the <literal>UPDATE</literal> command will see to operate against,
while the <literal>WITH CHECK</literal> expression defines which
modified rows are allowed to be stored back into the relation.
</para>
<para>
@ -285,15 +287,15 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
overlapping <literal>SELECT</literal> related policies found) with the
<literal>USING</literal> clause of the <literal>UPDATE</literal> policy
using AND. Therefore, in order for a user to be able to
<literal>UPDATE</literal> a specific set of rows using a
<literal>WHERE</literal> clause, the user must have access to the
row(s) through a <literal>SELECT</literal> or <literal>ALL</literal>
policy and the row(s) must be pass the <literal>UPDATE USING</literal>
<literal>UPDATE</literal> specific rows, the user must have access
to the row(s) through a <literal>SELECT</literal>
or <literal>ALL</literal> policy and the row(s) must pass
the <literal>UPDATE</literal> policy's <literal>USING</>
expression.
</para>
<para>
Any rows whose resulting values do not pass the
Any rows whose updated values do not pass the
<literal>WITH CHECK</literal> expression will cause an error, and the
entire command will be aborted. If only a <literal>USING</literal>
clause is specified, then that clause will be used for both
@ -307,9 +309,10 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
<literal>WITH CHECK</literal> expression. This
<literal>UPDATE</literal> policy must always pass when the
<literal>UPDATE</literal> path is taken. Any existing row that
necessitates that the <literal>UPDATE</literal> path be taken must pass
the (<literal>UPDATE</literal> or <literal>ALL</literal>) <literal>USING</literal> qualifications (combined
using <quote>or</quote>), which are always enforced as <literal>WITH CHECK</literal>
necessitates that the <literal>UPDATE</literal> path be taken must
pass the (<literal>UPDATE</literal> or <literal>ALL</literal>)
<literal>USING</literal> qualifications (combined using OR), which
are always enforced as <literal>WITH CHECK</literal>
options in this context. (The <literal>UPDATE</literal> path will
<emphasis>never</> be silently avoided; an error will be thrown
instead.) Finally, the final row appended to the relation must pass
@ -327,8 +330,9 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
to <literal>DELETE</literal> commands. Only rows that pass this
policy will be seen by a <literal>DELETE</literal> command. There can
be rows that are visible through a <literal>SELECT</literal> that are
not seen by a <literal>DELETE</literal>, if they do not pass the
<literal>USING</literal> expression for the <literal>DELETE</literal>.
not available for deletion, if they do not pass the
<literal>USING</literal> expression for
the <literal>DELETE</literal> policy.
</para>
<para>
@ -340,17 +344,18 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
overlapping <literal>SELECT</literal> related policies found) with the
<literal>USING</literal> clause of the <literal>DELETE</literal> policy
using AND. Therefore, in order for a user to be able to
<literal>DELETE</literal> a specific set of rows using a
<literal>WHERE</literal> clause, the user must have access to the
row(s) through a <literal>SELECT</literal> or <literal>ALL</literal>
policy and the row(s) must be pass the <literal>DELETE USING</literal>
<literal>DELETE</literal> specific rows, the user must have access
to the row(s) through a <literal>SELECT</literal>
or <literal>ALL</literal> policy and the row(s) must pass
the <literal>DELETE</literal> policy's <literal>USING</>
expression.
</para>
<para>
The <literal>DELETE</literal> policy only accepts the
<literal>USING</literal> expression as it only applies in cases where
records are being extracted from the relation for deletion.
A <literal>DELETE</literal> policy cannot have a <literal>WITH
CHECK</literal> expression, as it only applies in cases where
records are being deleted from the relation, so that there is no
new row to check.
</para>
</listitem>
</varlistentry>
@ -367,45 +372,58 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
</para>
<para>
Note that while policies will be applied for explicit queries against tables
in the system, they are not applied when the system is performing internal
While policies will be applied for explicit queries against tables
in the database, they are not applied when the system is performing internal
referential integrity checks or validating constraints. This means there are
indirect ways to determine that a given value exists. An example of this is
attempting to insert a duplicate value into a column which is the primary key
attempting to insert a duplicate value into a column that is a primary key
or has a unique constraint. If the insert fails then the user can infer that
the value already exists. (This example assumes that the user is permitted by
the value already exists. (This example assumes that the user is permitted by
policy to insert records which they are not allowed to see.) Another example
is where a user is allowed to insert into a table which references another,
otherwise hidden table. Existence can be determined by the user inserting
values into the referencing table, where success would indicate that the
value exists in the referenced table. These issues can be addressed by
carefully crafting policies that prevent users from being able to insert,
carefully crafting policies to prevent users from being able to insert,
delete, or update records at all which might possibly indicate a value they
are not otherwise able to see, or by using generated values (e.g., surrogate
keys) instead.
keys) instead of keys with external meanings.
</para>
<para>
Regarding how policy expressions interact with the user: as the expressions
Generally, the system will enforce filter conditions imposed using
security policies prior to qualifications that appear in user queries,
in order to prevent inadvertent exposure of the protected data to
user-defined functions which might not be trustworthy. However,
functions and operators marked by the system (or the system
administrator) as <literal>LEAKPROOF</literal> may be evaluated before
policy expressions, as they are assumed to be trustworthy.
</para>
<para>
Since policy expressions
are added to the user's query directly, they will be run with the rights of
the user running the overall query. Therefore, users who are using a given
policy must be able to access any tables or functions referenced in the
expression or they will simply receive a permission denied error when
attempting to query the table that has row-level security enabled. This does not change how views
attempting to query the table that has row-level security enabled.
This does not change how views
work, however. As with normal queries and views, permission checks and
policies for the tables which are referenced by a view will use the view
owner's rights and any policies which apply to the view owner.
</para>
<para>
When reducing the set of rows which a user has access to, through
modifications to relations referenced by Row-Level Security Policies or
Security Barrier Views, be aware that users with a currently open transaction
may be able to see updates to the rows that they are no longer allowed
access. Therefore, the best practice to avoid any possible leak of
When reducing the set of rows which users have access to, through
modifications to row-level security policies or security-barrier views,
be aware that users with a currently open transaction may be able to see
updates to rows that they are theoretically no longer allowed access to,
as the new policies may not be absorbed into existing query plans
immediately. Therefore, the best practice to avoid any possible leak of
information when altering conditions that determine the visibility of
specific rows is to ensure that affected users do not have any open
transactions, perhaps by ensuring they have no concurrent sessions running.
transactions, perhaps by ensuring they have no concurrent sessions
running.
</para>
</refsect1>
@ -425,6 +443,7 @@ CREATE POLICY <replaceable class="parameter">name</replaceable> ON <replaceable
<simplelist type="inline">
<member><xref linkend="sql-alterpolicy"></member>
<member><xref linkend="sql-droppolicy"></member>
<member><xref linkend="sql-altertable"></member>
</simplelist>
</refsect1>

View File

@ -16,7 +16,7 @@ PostgreSQL documentation
<refnamediv>
<refname>DROP POLICY</refname>
<refpurpose>remove a policy from a table</refpurpose>
<refpurpose>remove a row level security policy from a table</refpurpose>
</refnamediv>
<refsynopsisdiv>
@ -32,10 +32,9 @@ DROP POLICY [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ON <
<command>DROP POLICY</command> removes the specified policy from the table.
Note that if the last policy is removed for a table and the table still has
row level security enabled via <command>ALTER TABLE</command>, then the
default-deny policy will be used. <command>ALTER TABLE</command> can be used
to disable row level security for a table using
<literal>DISABLE ROW SECURITY</literal>, whether policies for the table
exist or not.
default-deny policy will be used. <literal>ALTER TABLE ... DISABLE ROW
LEVEL SECURITY</literal> can be used to disable row level security for a
table, whether policies for the table exist or not.
</para>
</refsect1>