gooderp18绿色标准版
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

387 lines
22KB

  1. <?xml version="1.0" encoding="UTF-8" standalone="no"?>
  2. <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>5.8. Row Security Policies</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets V1.79.1" /><link rel="prev" href="ddl-priv.html" title="5.7. Privileges" /><link rel="next" href="ddl-schemas.html" title="5.9. Schemas" /></head><body><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">5.8. Row Security Policies</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="ddl-priv.html" title="5.7. Privileges">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="ddl.html" title="Chapter 5. Data Definition">Up</a></td><th width="60%" align="center">Chapter 5. Data Definition</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 12.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="ddl-schemas.html" title="5.9. Schemas">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="DDL-ROWSECURITY"><div class="titlepage"><div><div><h2 class="title" style="clear: both">5.8. Row Security Policies</h2></div></div></div><a id="id-1.5.4.10.2" class="indexterm"></a><a id="id-1.5.4.10.3" class="indexterm"></a><p>
  3. In addition to the SQL-standard <a class="link" href="ddl-priv.html" title="5.7. Privileges">privilege
  4. system</a> available through <a class="xref" href="sql-grant.html" title="GRANT"><span class="refentrytitle">GRANT</span></a>,
  5. tables can have <em class="firstterm">row security policies</em> that restrict,
  6. on a per-user basis, which rows can be returned by normal queries
  7. or inserted, updated, or deleted by data modification commands.
  8. This feature is also known as <em class="firstterm">Row-Level Security</em>.
  9. By default, tables do not have any policies, so that if a user has
  10. access privileges to a table according to the SQL privilege system,
  11. all rows within it are equally available for querying or updating.
  12. </p><p>
  13. When row security is enabled on a table (with
  14. <a class="link" href="sql-altertable.html" title="ALTER TABLE">ALTER TABLE ... ENABLE ROW LEVEL
  15. SECURITY</a>), all normal access to the table for selecting rows or
  16. modifying rows must be allowed by a row security policy. (However, the
  17. table's owner is typically not subject to row security policies.) If no
  18. policy exists for the table, a default-deny policy is used, meaning that
  19. no rows are visible or can be modified. Operations that apply to the
  20. whole table, such as <code class="command">TRUNCATE</code> and <code class="literal">REFERENCES</code>,
  21. are not subject to row security.
  22. </p><p>
  23. Row security policies can be specific to commands, or to roles, or to
  24. both. A policy can be specified to apply to <code class="literal">ALL</code>
  25. commands, or to <code class="literal">SELECT</code>, <code class="literal">INSERT</code>, <code class="literal">UPDATE</code>,
  26. or <code class="literal">DELETE</code>. Multiple roles can be assigned to a given
  27. policy, and normal role membership and inheritance rules apply.
  28. </p><p>
  29. To specify which rows are visible or modifiable according to a policy,
  30. an expression is required that returns a Boolean result. This
  31. expression will be evaluated for each row prior to any conditions or
  32. functions coming from the user's query. (The only exceptions to this
  33. rule are <code class="literal">leakproof</code> functions, which are guaranteed to
  34. not leak information; the optimizer may choose to apply such functions
  35. ahead of the row-security check.) Rows for which the expression does
  36. not return <code class="literal">true</code> will not be processed. Separate expressions
  37. may be specified to provide independent control over the rows which are
  38. visible and the rows which are allowed to be modified. Policy
  39. expressions are run as part of the query and with the privileges of the
  40. user running the query, although security-definer functions can be used
  41. to access data not available to the calling user.
  42. </p><p>
  43. Superusers and roles with the <code class="literal">BYPASSRLS</code> attribute always
  44. bypass the row security system when accessing a table. Table owners
  45. normally bypass row security as well, though a table owner can choose to
  46. be subject to row security with <a class="link" href="sql-altertable.html" title="ALTER TABLE">ALTER
  47. TABLE ... FORCE ROW LEVEL SECURITY</a>.
  48. </p><p>
  49. Enabling and disabling row security, as well as adding policies to a
  50. table, is always the privilege of the table owner only.
  51. </p><p>
  52. Policies are created using the <a class="xref" href="sql-createpolicy.html" title="CREATE POLICY"><span class="refentrytitle">CREATE POLICY</span></a>
  53. command, altered using the <a class="xref" href="sql-alterpolicy.html" title="ALTER POLICY"><span class="refentrytitle">ALTER POLICY</span></a> command,
  54. and dropped using the <a class="xref" href="sql-droppolicy.html" title="DROP POLICY"><span class="refentrytitle">DROP POLICY</span></a> command. To
  55. enable and disable row security for a given table, use the
  56. <a class="xref" href="sql-altertable.html" title="ALTER TABLE"><span class="refentrytitle">ALTER TABLE</span></a> command.
  57. </p><p>
  58. Each policy has a name and multiple policies can be defined for a
  59. table. As policies are table-specific, each policy for a table must
  60. have a unique name. Different tables may have policies with the
  61. same name.
  62. </p><p>
  63. When multiple policies apply to a given query, they are combined using
  64. either <code class="literal">OR</code> (for permissive policies, which are the
  65. default) or using <code class="literal">AND</code> (for restrictive policies).
  66. This is similar to the rule that a given role has the privileges
  67. of all roles that they are a member of. Permissive vs. restrictive
  68. policies are discussed further below.
  69. </p><p>
  70. As a simple example, here is how to create a policy on
  71. the <code class="literal">account</code> relation to allow only members of
  72. the <code class="literal">managers</code> role to access rows, and only rows of their
  73. accounts:
  74. </p><pre class="programlisting">
  75. CREATE TABLE accounts (manager text, company text, contact_email text);
  76. ALTER TABLE accounts ENABLE ROW LEVEL SECURITY;
  77. CREATE POLICY account_managers ON accounts TO managers
  78. USING (manager = current_user);
  79. </pre><p>
  80. The policy above implicitly provides a <code class="literal">WITH CHECK</code>
  81. clause identical to its <code class="literal">USING</code> clause, so that the
  82. constraint applies both to rows selected by a command (so a manager
  83. cannot <code class="command">SELECT</code>, <code class="command">UPDATE</code>,
  84. or <code class="command">DELETE</code> existing rows belonging to a different
  85. manager) and to rows modified by a command (so rows belonging to a
  86. different manager cannot be created via <code class="command">INSERT</code>
  87. or <code class="command">UPDATE</code>).
  88. </p><p>
  89. If no role is specified, or the special user name
  90. <code class="literal">PUBLIC</code> is used, then the policy applies to all
  91. users on the system. To allow all users to access only their own row in
  92. a <code class="literal">users</code> table, a simple policy can be used:
  93. </p><pre class="programlisting">
  94. CREATE POLICY user_policy ON users
  95. USING (user_name = current_user);
  96. </pre><p>
  97. This works similarly to the previous example.
  98. </p><p>
  99. To use a different policy for rows that are being added to the table
  100. compared to those rows that are visible, multiple policies can be
  101. combined. This pair of policies would allow all users to view all rows
  102. in the <code class="literal">users</code> table, but only modify their own:
  103. </p><pre class="programlisting">
  104. CREATE POLICY user_sel_policy ON users
  105. FOR SELECT
  106. USING (true);
  107. CREATE POLICY user_mod_policy ON users
  108. USING (user_name = current_user);
  109. </pre><p>
  110. In a <code class="command">SELECT</code> command, these two policies are combined
  111. using <code class="literal">OR</code>, with the net effect being that all rows
  112. can be selected. In other command types, only the second policy applies,
  113. so that the effects are the same as before.
  114. </p><p>
  115. Row security can also be disabled with the <code class="command">ALTER TABLE</code>
  116. command. Disabling row security does not remove any policies that are
  117. defined on the table; they are simply ignored. Then all rows in the
  118. table are visible and modifiable, subject to the standard SQL privileges
  119. system.
  120. </p><p>
  121. Below is a larger example of how this feature can be used in production
  122. environments. The table <code class="literal">passwd</code> emulates a Unix password
  123. file:
  124. </p><pre class="programlisting">
  125. -- Simple passwd-file based example
  126. CREATE TABLE passwd (
  127. user_name text UNIQUE NOT NULL,
  128. pwhash text,
  129. uid int PRIMARY KEY,
  130. gid int NOT NULL,
  131. real_name text NOT NULL,
  132. home_phone text,
  133. extra_info text,
  134. home_dir text NOT NULL,
  135. shell text NOT NULL
  136. );
  137. CREATE ROLE admin; -- Administrator
  138. CREATE ROLE bob; -- Normal user
  139. CREATE ROLE alice; -- Normal user
  140. -- Populate the table
  141. INSERT INTO passwd VALUES
  142. ('admin','xxx',0,0,'Admin','111-222-3333',null,'/root','/bin/dash');
  143. INSERT INTO passwd VALUES
  144. ('bob','xxx',1,1,'Bob','123-456-7890',null,'/home/bob','/bin/zsh');
  145. INSERT INTO passwd VALUES
  146. ('alice','xxx',2,1,'Alice','098-765-4321',null,'/home/alice','/bin/zsh');
  147. -- Be sure to enable row level security on the table
  148. ALTER TABLE passwd ENABLE ROW LEVEL SECURITY;
  149. -- Create policies
  150. -- Administrator can see all rows and add any rows
  151. CREATE POLICY admin_all ON passwd TO admin USING (true) WITH CHECK (true);
  152. -- Normal users can view all rows
  153. CREATE POLICY all_view ON passwd FOR SELECT USING (true);
  154. -- Normal users can update their own records, but
  155. -- limit which shells a normal user is allowed to set
  156. CREATE POLICY user_mod ON passwd FOR UPDATE
  157. USING (current_user = user_name)
  158. WITH CHECK (
  159. current_user = user_name AND
  160. shell IN ('/bin/bash','/bin/sh','/bin/dash','/bin/zsh','/bin/tcsh')
  161. );
  162. -- Allow admin all normal rights
  163. GRANT SELECT, INSERT, UPDATE, DELETE ON passwd TO admin;
  164. -- Users only get select access on public columns
  165. GRANT SELECT
  166. (user_name, uid, gid, real_name, home_phone, extra_info, home_dir, shell)
  167. ON passwd TO public;
  168. -- Allow users to update certain columns
  169. GRANT UPDATE
  170. (pwhash, real_name, home_phone, extra_info, shell)
  171. ON passwd TO public;
  172. </pre><p>
  173. As with any security settings, it's important to test and ensure that
  174. the system is behaving as expected. Using the example above, this
  175. demonstrates that the permission system is working properly.
  176. </p><pre class="programlisting">
  177. -- admin can view all rows and fields
  178. postgres=&gt; set role admin;
  179. SET
  180. postgres=&gt; table passwd;
  181. user_name | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell
  182. -----------+--------+-----+-----+-----------+--------------+------------+-------------+-----------
  183. admin | xxx | 0 | 0 | Admin | 111-222-3333 | | /root | /bin/dash
  184. bob | xxx | 1 | 1 | Bob | 123-456-7890 | | /home/bob | /bin/zsh
  185. alice | xxx | 2 | 1 | Alice | 098-765-4321 | | /home/alice | /bin/zsh
  186. (3 rows)
  187. -- Test what Alice is able to do
  188. postgres=&gt; set role alice;
  189. SET
  190. postgres=&gt; table passwd;
  191. ERROR: permission denied for relation passwd
  192. postgres=&gt; select user_name,real_name,home_phone,extra_info,home_dir,shell from passwd;
  193. user_name | real_name | home_phone | extra_info | home_dir | shell
  194. -----------+-----------+--------------+------------+-------------+-----------
  195. admin | Admin | 111-222-3333 | | /root | /bin/dash
  196. bob | Bob | 123-456-7890 | | /home/bob | /bin/zsh
  197. alice | Alice | 098-765-4321 | | /home/alice | /bin/zsh
  198. (3 rows)
  199. postgres=&gt; update passwd set user_name = 'joe';
  200. ERROR: permission denied for relation passwd
  201. -- Alice is allowed to change her own real_name, but no others
  202. postgres=&gt; update passwd set real_name = 'Alice Doe';
  203. UPDATE 1
  204. postgres=&gt; update passwd set real_name = 'John Doe' where user_name = 'admin';
  205. UPDATE 0
  206. postgres=&gt; update passwd set shell = '/bin/xx';
  207. ERROR: new row violates WITH CHECK OPTION for "passwd"
  208. postgres=&gt; delete from passwd;
  209. ERROR: permission denied for relation passwd
  210. postgres=&gt; insert into passwd (user_name) values ('xxx');
  211. ERROR: permission denied for relation passwd
  212. -- Alice can change her own password; RLS silently prevents updating other rows
  213. postgres=&gt; update passwd set pwhash = 'abc';
  214. UPDATE 1
  215. </pre><p>
  216. All of the policies constructed thus far have been permissive policies,
  217. meaning that when multiple policies are applied they are combined using
  218. the <span class="quote">“<span class="quote">OR</span>”</span> Boolean operator. While permissive policies can be constructed
  219. to only allow access to rows in the intended cases, it can be simpler to
  220. combine permissive policies with restrictive policies (which the records
  221. must pass and which are combined using the <span class="quote">“<span class="quote">AND</span>”</span> Boolean operator).
  222. Building on the example above, we add a restrictive policy to require
  223. the administrator to be connected over a local Unix socket to access the
  224. records of the <code class="literal">passwd</code> table:
  225. </p><pre class="programlisting">
  226. CREATE POLICY admin_local_only ON passwd AS RESTRICTIVE TO admin
  227. USING (pg_catalog.inet_client_addr() IS NULL);
  228. </pre><p>
  229. We can then see that an administrator connecting over a network will not
  230. see any records, due to the restrictive policy:
  231. </p><pre class="programlisting">
  232. =&gt; SELECT current_user;
  233. current_user
  234. --------------
  235. admin
  236. (1 row)
  237. =&gt; select inet_client_addr();
  238. inet_client_addr
  239. ------------------
  240. 127.0.0.1
  241. (1 row)
  242. =&gt; SELECT current_user;
  243. current_user
  244. --------------
  245. admin
  246. (1 row)
  247. =&gt; TABLE passwd;
  248. user_name | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell
  249. -----------+--------+-----+-----+-----------+------------+------------+----------+-------
  250. (0 rows)
  251. =&gt; UPDATE passwd set pwhash = NULL;
  252. UPDATE 0
  253. </pre><p>
  254. Referential integrity checks, such as unique or primary key constraints
  255. and foreign key references, always bypass row security to ensure that
  256. data integrity is maintained. Care must be taken when developing
  257. schemas and row level policies to avoid <span class="quote">“<span class="quote">covert channel</span>”</span> leaks of
  258. information through such referential integrity checks.
  259. </p><p>
  260. In some contexts it is important to be sure that row security is
  261. not being applied. For example, when taking a backup, it could be
  262. disastrous if row security silently caused some rows to be omitted
  263. from the backup. In such a situation, you can set the
  264. <a class="xref" href="runtime-config-client.html#GUC-ROW-SECURITY">row_security</a> configuration parameter
  265. to <code class="literal">off</code>. This does not in itself bypass row security;
  266. what it does is throw an error if any query's results would get filtered
  267. by a policy. The reason for the error can then be investigated and
  268. fixed.
  269. </p><p>
  270. In the examples above, the policy expressions consider only the current
  271. values in the row to be accessed or updated. This is the simplest and
  272. best-performing case; when possible, it's best to design row security
  273. applications to work this way. If it is necessary to consult other rows
  274. or other tables to make a policy decision, that can be accomplished using
  275. sub-<code class="command">SELECT</code>s, or functions that contain <code class="command">SELECT</code>s,
  276. in the policy expressions. Be aware however that such accesses can
  277. create race conditions that could allow information leakage if care is
  278. not taken. As an example, consider the following table design:
  279. </p><pre class="programlisting">
  280. -- definition of privilege groups
  281. CREATE TABLE groups (group_id int PRIMARY KEY,
  282. group_name text NOT NULL);
  283. INSERT INTO groups VALUES
  284. (1, 'low'),
  285. (2, 'medium'),
  286. (5, 'high');
  287. GRANT ALL ON groups TO alice; -- alice is the administrator
  288. GRANT SELECT ON groups TO public;
  289. -- definition of users' privilege levels
  290. CREATE TABLE users (user_name text PRIMARY KEY,
  291. group_id int NOT NULL REFERENCES groups);
  292. INSERT INTO users VALUES
  293. ('alice', 5),
  294. ('bob', 2),
  295. ('mallory', 2);
  296. GRANT ALL ON users TO alice;
  297. GRANT SELECT ON users TO public;
  298. -- table holding the information to be protected
  299. CREATE TABLE information (info text,
  300. group_id int NOT NULL REFERENCES groups);
  301. INSERT INTO information VALUES
  302. ('barely secret', 1),
  303. ('slightly secret', 2),
  304. ('very secret', 5);
  305. ALTER TABLE information ENABLE ROW LEVEL SECURITY;
  306. -- a row should be visible to/updatable by users whose security group_id is
  307. -- greater than or equal to the row's group_id
  308. CREATE POLICY fp_s ON information FOR SELECT
  309. USING (group_id &lt;= (SELECT group_id FROM users WHERE user_name = current_user));
  310. CREATE POLICY fp_u ON information FOR UPDATE
  311. USING (group_id &lt;= (SELECT group_id FROM users WHERE user_name = current_user));
  312. -- we rely only on RLS to protect the information table
  313. GRANT ALL ON information TO public;
  314. </pre><p>
  315. Now suppose that <code class="literal">alice</code> wishes to change the <span class="quote">“<span class="quote">slightly
  316. secret</span>”</span> information, but decides that <code class="literal">mallory</code> should not
  317. be trusted with the new content of that row, so she does:
  318. </p><pre class="programlisting">
  319. BEGIN;
  320. UPDATE users SET group_id = 1 WHERE user_name = 'mallory';
  321. UPDATE information SET info = 'secret from mallory' WHERE group_id = 2;
  322. COMMIT;
  323. </pre><p>
  324. That looks safe; there is no window wherein <code class="literal">mallory</code> should be
  325. able to see the <span class="quote">“<span class="quote">secret from mallory</span>”</span> string. However, there is
  326. a race condition here. If <code class="literal">mallory</code> is concurrently doing,
  327. say,
  328. </p><pre class="programlisting">
  329. SELECT * FROM information WHERE group_id = 2 FOR UPDATE;
  330. </pre><p>
  331. and her transaction is in <code class="literal">READ COMMITTED</code> mode, it is possible
  332. for her to see <span class="quote">“<span class="quote">secret from mallory</span>”</span>. That happens if her
  333. transaction reaches the <code class="structname">information</code> row just
  334. after <code class="literal">alice</code>'s does. It blocks waiting
  335. for <code class="literal">alice</code>'s transaction to commit, then fetches the updated
  336. row contents thanks to the <code class="literal">FOR UPDATE</code> clause. However, it
  337. does <span class="emphasis"><em>not</em></span> fetch an updated row for the
  338. implicit <code class="command">SELECT</code> from <code class="structname">users</code>, because that
  339. sub-<code class="command">SELECT</code> did not have <code class="literal">FOR UPDATE</code>; instead
  340. the <code class="structname">users</code> row is read with the snapshot taken at the start
  341. of the query. Therefore, the policy expression tests the old value
  342. of <code class="literal">mallory</code>'s privilege level and allows her to see the
  343. updated row.
  344. </p><p>
  345. There are several ways around this problem. One simple answer is to use
  346. <code class="literal">SELECT ... FOR SHARE</code> in sub-<code class="command">SELECT</code>s in row
  347. security policies. However, that requires granting <code class="literal">UPDATE</code>
  348. privilege on the referenced table (here <code class="structname">users</code>) to the
  349. affected users, which might be undesirable. (But another row security
  350. policy could be applied to prevent them from actually exercising that
  351. privilege; or the sub-<code class="command">SELECT</code> could be embedded into a security
  352. definer function.) Also, heavy concurrent use of row share locks on the
  353. referenced table could pose a performance problem, especially if updates
  354. of it are frequent. Another solution, practical if updates of the
  355. referenced table are infrequent, is to take an exclusive lock on the
  356. referenced table when updating it, so that no concurrent transactions
  357. could be examining old row values. Or one could just wait for all
  358. concurrent transactions to end after committing an update of the
  359. referenced table and before making changes that rely on the new security
  360. situation.
  361. </p><p>
  362. For additional details see <a class="xref" href="sql-createpolicy.html" title="CREATE POLICY"><span class="refentrytitle">CREATE POLICY</span></a>
  363. and <a class="xref" href="sql-altertable.html" title="ALTER TABLE"><span class="refentrytitle">ALTER TABLE</span></a>.
  364. </p></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="ddl-priv.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="ddl.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="ddl-schemas.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">5.7. Privileges </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 5.9. Schemas</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1