CREATE ROW LEVEL SECURITY POLICY

Function

Creates a row-level access control policy for a table.

The policy takes effect only after row-level access control is enabled (by running ALTER TABLE... ENABLE ROW LEVEL SECURITY).

Currently, row-level access control affects the read (SELECT, UPDATE, DELETE) of data tables and does not affect the write (INSERT and MERGE INTO) of data tables. The table owner or system administrators can create an expression in the USING clause. When the client reads the data table, the database server combines the expressions that meet the condition and applies it to the execution plan in the statement rewriting phase of a query. For each tuple in a data table, if the expression returns TRUE, the tuple is visible to the current user; if the expression returns FALSE or NULL, the tuple is invisible to the current user.

A row-level access control policy name is specific to a table. A data table cannot have row-level access control policies with the same name. Different data tables can have the same row-level access control policy.

Row-level access control policies can be applied to specified operations (SELECT, UPDATE, DELETE, and ALL). ALL indicates that SELECT, UPDATE, and DELETE will be affected. For a new row-level access control policy, the default value ALL will be used if you do not specify the operations that will be affected.

Row-level access control policies can be applied to a specified user (role) or to all users (PUBLIC). For a new row-level access control policy, the default value PUBLIC will be used if you do not specify the user that will be affected.

Precautions

Syntax

1
2
3
4
5
CREATE [ ROW LEVEL SECURITY ] POLICY policy_name ON table_name
    [ AS { PERMISSIVE | RESTRICTIVE } ]
    [ FOR { ALL | SELECT | UPDATE | DELETE } ]
    [ TO { role_name | PUBLIC } [, ...] ]
    USING ( using_expression )

Parameter Description

Example 1: Create a Row-level Access Control Policy That the Current User Can Only View Its Own Data.

  1. Create users alice and bob.
    1
    2
    CREATE ROLE alice PASSWORD '{password}';
    CREATE ROLE bob PASSWORD '{password}';
    
  2. Create data table public.all_data:
    1
    CREATE TABLE public.all_data(id int, role varchar(100), data varchar(100));
    
  3. Insert data into the data table:
    1
    2
    3
    INSERT INTO all_data VALUES(1, 'alice', 'alice data');
    INSERT INTO all_data VALUES(2, 'bob', 'bob data');
    INSERT INTO all_data VALUES(3, 'peter', 'peter data');
    
  4. Grant the read permission for the all_data table to users alice and bob:
    1
    GRANT SELECT ON all_data TO alice, bob;
    
  5. Enable row-level access control.
    1
    ALTER TABLE all_data ENABLE ROW LEVEL SECURITY;
    
  6. Create a row-level access control policy to specify that the current user can view only their own data:
    1
    CREATE ROW LEVEL SECURITY POLICY all_data_rls ON all_data USING(role = CURRENT_USER);
    
  7. View information about the all_data table.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    \d+ all_data
                                   Table "public.all_data"
     Column |          Type          | Modifiers | Storage  | Stats target | Description
    --------+------------------------+-----------+----------+--------------+-------------
     id     | integer                |           | plain    |              |
     role   | character varying(100) |           | extended |              |
     data   | character varying(100) |           | extended |              |
    Row Level Security Policies:
        POLICY "all_data_rls"
          USING (((role)::name = "current_user"()))
    Has OIDs: no
    Distribute By: HASH(id)
    Location Nodes: ALL DATANODES
    Options: orientation=row, compression=no, enable_rowsecurity=true
    
  8. Run SELECT.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    SELECT * FROM all_data;
     id | role  |    data
    ----+-------+------------
      1 | alice | alice data
      2 | bob   | bob data
      3 | peter | peter data
    (3 rows)
    EXPLAIN(COSTS OFF) SELECT * FROM all_data;
             QUERY PLAN
    ----------------------------
     Streaming (type: GATHER)
       Node/s: All datanodes
       ->  Seq Scan on all_data
    (3 rows)
    
  9. Switch to the alice user.
    1
    set role alice password '{password}';
    
  10. Perform the SELECT operation.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    SELECT * FROM all_data;
     id | role  |    data
    ----+-------+------------
      1 | alice | alice data
    (1 row)
    
    EXPLAIN(COSTS OFF) SELECT * FROM all_data;
                               QUERY PLAN
    ----------------------------------------------------------------
     Streaming (type: GATHER)
       Node/s: All datanodes
       ->  Seq Scan on all_data
             Filter: ((role)::name = 'alice'::name)
     Notice: This query is influenced by row level security feature
    (5 rows)
    

Example 2: Partition Permission Management Through Row-Level Control

  1. Create user alice.
    1
    CREATE ROLE alice PASSWORD '{password1}';
    
  2. Create range partitioned table web_returns_p1, and insert data into the table.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    CREATE TABLE web_returns_p1
    (
        wr_returned_date_sk       integer,
        wr_returned_time_sk       integer,
        wr_item_sk                integer NOT NULL,
        wr_refunded_customer_sk   integer
    )
    WITH (orientation = column)
    DISTRIBUTE BY HASH (wr_item_sk)
    PARTITION BY RANGE(wr_returned_date_sk)
    (
        PARTITION p2016 START(800) END(830) EVERY(1)
    );
    
    INSERT INTO web_returns_p1 values (801,17,11,102);
    INSERT INTO web_returns_p1 values (802,18,12,103);
    
  3. Grant the read permission on the web_returns_p1 table to user alice.
    1
    GRANT SELECT ON web_returns_p1 TO alice;
    
  4. Enable row-level access control.
    1
    ALTER TABLE web_returns_p1 ENABLE ROW LEVEL SECURITY;
    
  5. Create row-level access control policy web_returns_rsl. In the command, wr_returned_date_sk is a partition name of the web_returns_p1 partition table, and 801 is the partition value.
    1
    CREATE ROW LEVEL SECURITY POLICY web_returns_rsl ON web_returns_p1 USING('wr_returned_date_sk' = '801');
    
  6. Impose the row-level access control policy web_returns_rsl on user alice.
    1
    ALTER ROW LEVEL SECURITY POLICY web_returns_rsl ON web_returns_p1 TO alice;
    
  7. Switch to the alice user.
    1
    set role alice password '{password1}';
    
  8. Query the web_returns_p1 table.
    1
    select * from web_returns_p1;
    

Helpful Links

DROP ROW LEVEL SECURITY POLICY