PostgreSQL 9.5beta2 Documentation | |||
---|---|---|---|
Prev | Up | Chapter 5. Data Definition | Next |
In addition to the Section 5.6 system available through 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 Section 5.6 system. This is also known as Row Level Security.
When row security is enabled on a table with ALTER TABLE, 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 TRUNCATE, and REFERENCES are not subject to row security.
Row security policies can be specific to commands, or to roles, or to both. The commands available are ALL, SELECT, INSERT, UPDATE, and 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 BYPASSRLS attribute bypass the row security system when querying a table. Applications that expect to bypass all row security through those mechanisms should set row_security to off.
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 leakproof 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.
Enabling and disabling row security, as well as adding policies to a table, is always the privilege of the owner only.
Policies are created using the CREATE POLICY command, altered using the ALTER POLICY command, and dropped using the DROP POLICY command. To enable and disable row security for a given table, use the ALTER TABLE command.
Each policy has a name and multiple policies can be defined for a table. As policies are table-specific, each policy for a table must have a unique name. Different tables may have policies with the same name.
When multiple policies apply to a given query, they are combined using OR, similar to how a given role has the privileges of all roles which they are a member of.
Referential integrity checks, such as unique or primary key constraints and foreign key references, will 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.
To enable row security for a table, the ALTER TABLE is used. For example, to enable row level security for the table accounts, use:
-- Create the table first CREATE TABLE accounts (manager text, company text, contact_email text); ALTER TABLE accounts ENABLE ROW LEVEL SECURITY;
To create a policy on the account relation to allow the managers role to view the rows of their accounts, the CREATE POLICY command can be used:
CREATE POLICY account_managers ON accounts TO managers USING (manager = current_user);
If no role is specified, or the special "user" name PUBLIC 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:
CREATE POLICY user_policy ON users USING (user = current_user);
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:
CREATE POLICY user_policy ON users USING (true) WITH CHECK (user = current_user);
Row security can be disabled with the ALTER TABLE 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.
Below is a larger example of how this feature can be used in production environments, based on a Unix password file.
-- Simple passwd-file based example CREATE TABLE passwd ( username text UNIQUE NOT NULL, pwhash text, uid int PRIMARY KEY, gid int NOT NULL, real_name text NOT NULL, home_phone text, extra_info text, home_dir text NOT NULL, shell text NOT NULL ); CREATE ROLE admin; -- Administrator CREATE ROLE bob; -- Normal user CREATE ROLE alice; -- Normal user -- Populate the table INSERT INTO passwd VALUES ('admin','xxx',0,0,'Admin','111-222-3333',null,'/root','/bin/dash'); INSERT INTO passwd VALUES ('bob','xxx',1,1,'Bob','123-456-7890',null,'/home/bob','/bin/zsh'); INSERT INTO passwd VALUES ('alice','xxx',2,1,'Alice','098-765-4321',null,'/home/alice','/bin/zsh'); -- Be sure to enable row level security on the table ALTER TABLE passwd ENABLE ROW LEVEL SECURITY; -- Create policies -- Administrator can see all rows and add any rows CREATE POLICY admin_all ON passwd TO admin USING (true) WITH CHECK (true); -- Normal users can view all rows CREATE POLICY all_view ON passwd FOR SELECT USING (true); -- Normal users can update their own records, but -- limit which shells a normal user is allowed to set CREATE POLICY user_mod ON passwd FOR UPDATE USING (current_user = username) WITH CHECK ( current_user = username AND shell IN ('/bin/bash','/bin/sh','/bin/dash','/bin/zsh','/bin/tcsh') ); -- Allow admin all normal rights GRANT SELECT, INSERT, UPDATE, DELETE ON passwd TO admin; -- Users only get select access on public columns GRANT SELECT (username, uid, gid, real_name, home_phone, extra_info, home_dir, shell) ON passwd TO public; -- Allow users to update certain columns GRANT UPDATE (pwhash, real_name, home_phone, extra_info, shell) ON passwd TO public;
As with any security settings, it's important to test and ensure that the system is behaving as expected. Using the example above, this demonstrates that the permission system is working properly.
-- admin can view all rows and fields postgres=> set role admin; SET postgres=> table passwd; 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 alice | xxx | 2 | 1 | Alice | 098-765-4321 | | /home/alice | /bin/zsh (3 rows) -- Test what Alice is able to do postgres=> set role alice; SET postgres=> table passwd; ERROR: permission denied for relation passwd postgres=> select username,real_name,home_phone,extra_info,home_dir,shell from passwd; 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 alice | Alice | 098-765-4321 | | /home/alice | /bin/zsh (3 rows) postgres=> update passwd set username = 'joe'; ERROR: permission denied for relation passwd -- Allowed to change her own real_name, but no others postgres=> update passwd set real_name = 'Alice Doe'; UPDATE 1 postgres=> update passwd set real_name = 'John Doe' where username = 'admin'; UPDATE 0 postgres=> update passwd set shell = '/bin/xx'; ERROR: new row violates WITH CHECK OPTION for "passwd" postgres=> delete from passwd; ERROR: permission denied for relation passwd postgres=> insert into passwd (username) values ('xxx'); ERROR: permission denied for relation passwd -- Alice can change her own password postgres=> update passwd set pwhash = 'abc'; UPDATE 1