1CREATE POLICY(7) PostgreSQL 11.6 Documentation CREATE POLICY(7)
2
3
4
6 CREATE_POLICY - define a new row level security policy for a table
7
9 CREATE POLICY name ON table_name
10 [ AS { PERMISSIVE | RESTRICTIVE } ]
11 [ FOR { ALL | SELECT | INSERT | UPDATE | DELETE } ]
12 [ TO { role_name | PUBLIC | CURRENT_USER | SESSION_USER } [, ...] ]
13 [ USING ( using_expression ) ]
14 [ WITH CHECK ( check_expression ) ]
15
17 The CREATE POLICY command defines a new row-level security policy for a
18 table. Note that row-level security must be enabled on the table (using
19 ALTER TABLE ... ENABLE ROW LEVEL SECURITY) in order for created
20 policies to be applied.
21
22 A policy grants the permission to select, insert, update, or delete
23 rows that match the relevant policy expression. Existing table rows are
24 checked against the expression specified in USING, while new rows that
25 would be created via INSERT or UPDATE are checked against the
26 expression specified in WITH CHECK. When a USING expression returns
27 true for a given row then that row is visible to the user, while if
28 false or null is returned then the row is not visible. When a WITH
29 CHECK expression returns true for a row then that row is inserted or
30 updated, while if false or null is returned then an error occurs.
31
32 For INSERT and UPDATE statements, WITH CHECK expressions are enforced
33 after BEFORE triggers are fired, and before any actual data
34 modifications are made. Thus a BEFORE ROW trigger may modify the data
35 to be inserted, affecting the result of the security policy check.
36 WITH CHECK expressions are enforced before any other constraints.
37
38 Policy names are per-table. Therefore, one policy name can be used for
39 many different tables and have a definition for each table which is
40 appropriate to that table.
41
42 Policies can be applied for specific commands or for specific roles.
43 The default for newly created policies is that they apply for all
44 commands and roles, unless otherwise specified. Multiple policies may
45 apply to a single command; see below for more details. Table 240
46 summarizes how the different types of policy apply to specific
47 commands.
48
49 For policies that can have both USING and WITH CHECK expressions (ALL
50 and UPDATE), if no WITH CHECK expression is defined, then the USING
51 expression will be used both to determine which rows are visible
52 (normal USING case) and which new rows will be allowed to be added
53 (WITH CHECK case).
54
55 If row-level security is enabled for a table, but no applicable
56 policies exist, a “default deny” policy is assumed, so that no rows
57 will be visible or updatable.
58
60 name
61 The name of the policy to be created. This must be distinct from
62 the name of any other policy for the table.
63
64 table_name
65 The name (optionally schema-qualified) of the table the policy
66 applies to.
67
68 PERMISSIVE
69 Specify that the policy is to be created as a permissive policy.
70 All permissive policies which are applicable to a given query will
71 be combined together using the Boolean “OR” operator. By creating
72 permissive policies, administrators can add to the set of records
73 which can be accessed. Policies are permissive by default.
74
75 RESTRICTIVE
76 Specify that the policy is to be created as a restrictive policy.
77 All restrictive policies which are applicable to a given query will
78 be combined together using the Boolean “AND” operator. By creating
79 restrictive policies, administrators can reduce the set of records
80 which can be accessed as all restrictive policies must be passed
81 for each record.
82
83 Note that there needs to be at least one permissive policy to grant
84 access to records before restrictive policies can be usefully used
85 to reduce that access. If only restrictive policies exist, then no
86 records will be accessible. When a mix of permissive and
87 restrictive policies are present, a record is only accessible if at
88 least one of the permissive policies passes, in addition to all the
89 restrictive policies.
90
91 command
92 The command to which the policy applies. Valid options are ALL,
93 SELECT, INSERT, UPDATE, and DELETE. ALL is the default. See below
94 for specifics regarding how these are applied.
95
96 role_name
97 The role(s) to which the policy is to be applied. The default is
98 PUBLIC, which will apply the policy to all roles.
99
100 using_expression
101 Any SQL conditional expression (returning boolean). The conditional
102 expression cannot contain any aggregate or window functions. This
103 expression will be added to queries that refer to the table if row
104 level security is enabled. Rows for which the expression returns
105 true will be visible. Any rows for which the expression returns
106 false or null will not be visible to the user (in a SELECT), and
107 will not be available for modification (in an UPDATE or DELETE).
108 Such rows are silently suppressed; no error is reported.
109
110 check_expression
111 Any SQL conditional expression (returning boolean). The conditional
112 expression cannot contain any aggregate or window functions. This
113 expression will be used in INSERT and UPDATE queries against the
114 table if row level security is enabled. Only rows for which the
115 expression evaluates to true will be allowed. An error will be
116 thrown if the expression evaluates to false or null for any of the
117 records inserted or any of the records that result from the update.
118 Note that the check_expression is evaluated against the proposed
119 new contents of the row, not the original contents.
120
121 Per-Command Policies
122 ALL
123 Using ALL for a policy means that it will apply to all commands,
124 regardless of the type of command. If an ALL policy exists and more
125 specific policies exist, then both the ALL policy and the more
126 specific policy (or policies) will be applied. Additionally, ALL
127 policies will be applied to both the selection side of a query and
128 the modification side, using the USING expression for both cases if
129 only a USING expression has been defined.
130
131 As an example, if an UPDATE is issued, then the ALL policy will be
132 applicable both to what the UPDATE will be able to select as rows
133 to be updated (applying the USING expression), and to the resulting
134 updated rows, to check if they are permitted to be added to the
135 table (applying the WITH CHECK expression, if defined, and the
136 USING expression otherwise). If an INSERT or UPDATE command
137 attempts to add rows to the table that do not pass the ALL policy's
138 WITH CHECK expression, the entire command will be aborted.
139
140 SELECT
141 Using SELECT for a policy means that it will apply to SELECT
142 queries and whenever SELECT permissions are required on the
143 relation the policy is defined for. The result is that only those
144 records from the relation that pass the SELECT policy will be
145 returned during a SELECT query, and that queries that require
146 SELECT permissions, such as UPDATE, will also only see those
147 records that are allowed by the SELECT policy. A SELECT policy
148 cannot have a WITH CHECK expression, as it only applies in cases
149 where records are being retrieved from the relation.
150
151 INSERT
152 Using INSERT for a policy means that it will apply to INSERT
153 commands. Rows being inserted that do not pass this policy will
154 result in a policy violation error, and the entire INSERT command
155 will be aborted. An INSERT policy cannot have a USING expression,
156 as it only applies in cases where records are being added to the
157 relation.
158
159 Note that INSERT with ON CONFLICT DO UPDATE checks INSERT policies'
160 WITH CHECK expressions only for rows appended to the relation by
161 the INSERT path.
162
163 UPDATE
164 Using UPDATE for a policy means that it will apply to UPDATE,
165 SELECT FOR UPDATE and SELECT FOR SHARE commands, as well as
166 auxiliary ON CONFLICT DO UPDATE clauses of INSERT commands. Since
167 UPDATE involves pulling an existing record and replacing it with a
168 new modified record, UPDATE policies accept both a USING expression
169 and a WITH CHECK expression. The USING expression determines which
170 records the UPDATE command will see to operate against, while the
171 WITH CHECK expression defines which modified rows are allowed to be
172 stored back into the relation.
173
174 Any rows whose updated values do not pass the WITH CHECK expression
175 will cause an error, and the entire command will be aborted. If
176 only a USING clause is specified, then that clause will be used for
177 both USING and WITH CHECK cases.
178
179 Typically an UPDATE command also needs to read data from columns in
180 the relation being updated (e.g., in a WHERE clause or a RETURNING
181 clause, or in an expression on the right hand side of the SET
182 clause). In this case, SELECT rights are also required on the
183 relation being updated, and the appropriate SELECT or ALL policies
184 will be applied in addition to the UPDATE policies. Thus the user
185 must have access to the row(s) being updated through a SELECT or
186 ALL policy in addition to being granted permission to update the
187 row(s) via an UPDATE or ALL policy.
188
189 When an INSERT command has an auxiliary ON CONFLICT DO UPDATE
190 clause, if the UPDATE path is taken, the row to be updated is first
191 checked against the USING expressions of any UPDATE policies, and
192 then the new updated row is checked against the WITH CHECK
193 expressions. Note, however, that unlike a standalone UPDATE
194 command, if the existing row does not pass the USING expressions,
195 an error will be thrown (the UPDATE path will never be silently
196 avoided).
197
198 DELETE
199 Using DELETE for a policy means that it will apply to DELETE
200 commands. Only rows that pass this policy will be seen by a DELETE
201 command. There can be rows that are visible through a SELECT that
202 are not available for deletion, if they do not pass the USING
203 expression for the DELETE policy.
204
205 In most cases a DELETE command also needs to read data from columns
206 in the relation that it is deleting from (e.g., in a WHERE clause
207 or a RETURNING clause). In this case, SELECT rights are also
208 required on the relation, and the appropriate SELECT or ALL
209 policies will be applied in addition to the DELETE policies. Thus
210 the user must have access to the row(s) being deleted through a
211 SELECT or ALL policy in addition to being granted permission to
212 delete the row(s) via a DELETE or ALL policy.
213
214 A DELETE policy cannot have a WITH CHECK expression, as it only
215 applies in cases where records are being deleted from the relation,
216 so that there is no new row to check.
217
218 Table 240. Policies Applied by Command Type
219 ┌─────────────┬─────────────┬────────────┬─────────────────────────┬────────────┐
220 │ │ SELECT/ALL │ INSERT/ALL │ UPDATE/ALL policy │ DELETE/ALL │
221 │ │ policy │ policy │ │ policy │
222 │Command ├─────────────┼────────────┼────────────┬────────────┼────────────┤
223 │ │ USING │ WITH CHECK │ USING │ WITH CHECK │ USING │
224 │ │ expression │ expression │ expression │ expression │ expression │
225 ├─────────────┼─────────────┼────────────┼────────────┼────────────┼────────────┤
226 │SELECT │ Existing │ — │ — │ — │ — │
227 │ │ row │ │ │ │ │
228 ├─────────────┼─────────────┼────────────┼────────────┼────────────┼────────────┤
229 │SELECT FOR │ Existing │ — │ Existing │ — │ — │
230 │UPDATE/SHARE │ row │ │ row │ │ │
231 ├─────────────┼─────────────┼────────────┼────────────┼────────────┼────────────┤
232 │INSERT │ — │ New row │ — │ — │ — │
233 ├─────────────┼─────────────┼────────────┼────────────┼────────────┼────────────┤
234 │INSERT ... │ New row [a] │ New row │ — │ — │ — │
235 │RETURNING │ │ │ │ │ │
236 ├─────────────┼─────────────┼────────────┼────────────┼────────────┼────────────┤
237 │UPDATE │ Existing & │ — │ Existing │ New row │ — │
238 │ │ new rows │ │ row │ │ │
239 │ │ [a] │ │ │ │ │
240 ├─────────────┼─────────────┼────────────┼────────────┼────────────┼────────────┤
241 │DELETE │ Existing │ — │ — │ — │ Existing │
242 │ │ row [a] │ │ │ │ row │
243 ├─────────────┼─────────────┼────────────┼────────────┼────────────┼────────────┤
244 │ON CONFLICT │ Existing & │ — │ Existing │ New row │ — │
245 │DO UPDATE │ new rows │ │ row │ │ │
246 ├─────────────┴─────────────┴────────────┴────────────┴────────────┴────────────┤
247 │---- │
248 │[a] If read access is required to the existing or new row (for │
249 │example, a WHERE or RETURNING clause that refers to columns from │
250 │the relation). │
251 └───────────────────────────────────────────────────────────────────────────────┘
252
253 Application of Multiple Policies
254 When multiple policies of different command types apply to the same
255 command (for example, SELECT and UPDATE policies applied to an UPDATE
256 command), then the user must have both types of permissions (for
257 example, permission to select rows from the relation as well as
258 permission to update them). Thus the expressions for one type of policy
259 are combined with the expressions for the other type of policy using
260 the AND operator.
261
262 When multiple policies of the same command type apply to the same
263 command, then there must be at least one PERMISSIVE policy granting
264 access to the relation, and all of the RESTRICTIVE policies must pass.
265 Thus all the PERMISSIVE policy expressions are combined using OR, all
266 the RESTRICTIVE policy expressions are combined using AND, and the
267 results are combined using AND. If there are no PERMISSIVE policies,
268 then access is denied.
269
270 Note that, for the purposes of combining multiple policies, ALL
271 policies are treated as having the same type as whichever other type of
272 policy is being applied.
273
274 For example, in an UPDATE command requiring both SELECT and UPDATE
275 permissions, if there are multiple applicable policies of each type,
276 they will be combined as follows:
277
278 expression from RESTRICTIVE SELECT/ALL policy 1
279 AND
280 expression from RESTRICTIVE SELECT/ALL policy 2
281 AND
282 ...
283 AND
284 (
285 expression from PERMISSIVE SELECT/ALL policy 1
286 OR
287 expression from PERMISSIVE SELECT/ALL policy 2
288 OR
289 ...
290 )
291 AND
292 expression from RESTRICTIVE UPDATE/ALL policy 1
293 AND
294 expression from RESTRICTIVE UPDATE/ALL policy 2
295 AND
296 ...
297 AND
298 (
299 expression from PERMISSIVE UPDATE/ALL policy 1
300 OR
301 expression from PERMISSIVE UPDATE/ALL policy 2
302 OR
303 ...
304 )
305
307 You must be the owner of a table to create or change policies for it.
308
309 While policies will be applied for explicit queries against tables in
310 the database, they are not applied when the system is performing
311 internal referential integrity checks or validating constraints. This
312 means there are indirect ways to determine that a given value exists.
313 An example of this is attempting to insert a duplicate value into a
314 column that is a primary key or has a unique constraint. If the insert
315 fails then the user can infer that the value already exists. (This
316 example assumes that the user is permitted by policy to insert records
317 which they are not allowed to see.) Another example is where a user is
318 allowed to insert into a table which references another, otherwise
319 hidden table. Existence can be determined by the user inserting values
320 into the referencing table, where success would indicate that the value
321 exists in the referenced table. These issues can be addressed by
322 carefully crafting policies to prevent users from being able to insert,
323 delete, or update records at all which might possibly indicate a value
324 they are not otherwise able to see, or by using generated values (e.g.,
325 surrogate keys) instead of keys with external meanings.
326
327 Generally, the system will enforce filter conditions imposed using
328 security policies prior to qualifications that appear in user queries,
329 in order to prevent inadvertent exposure of the protected data to
330 user-defined functions which might not be trustworthy. However,
331 functions and operators marked by the system (or the system
332 administrator) as LEAKPROOF may be evaluated before policy expressions,
333 as they are assumed to be trustworthy.
334
335 Since policy expressions are added to the user's query directly, they
336 will be run with the rights of the user running the overall query.
337 Therefore, users who are using a given policy must be able to access
338 any tables or functions referenced in the expression or they will
339 simply receive a permission denied error when attempting to query the
340 table that has row-level security enabled. This does not change how
341 views work, however. As with normal queries and views, permission
342 checks and policies for the tables which are referenced by a view will
343 use the view owner's rights and any policies which apply to the view
344 owner.
345
346 Additional discussion and practical examples can be found in
347 Section 5.7.
348
350 CREATE POLICY is a PostgreSQL extension.
351
353 ALTER POLICY (ALTER_POLICY(7)), DROP POLICY (DROP_POLICY(7)), ALTER
354 TABLE (ALTER_TABLE(7))
355
356
357
358PostgreSQL 11.6 2019 CREATE POLICY(7)