1 # Copyright (C) The Arvados Authors. All rights reserved.
3 # SPDX-License-Identifier: AGPL-3.0
5 require '20200501150153_permission_table_constants'
7 class PermissionTable < ActiveRecord::Migration[5.0]
9 # This is a major migration. We are replacing the
10 # materialized_permission_view, which is fully recomputed any time
11 # a permission changes (and becomes very expensive as the number
12 # of users/groups becomes large), with a new strategy that only
13 # recomputes permissions for the subset of objects that are
14 # potentially affected by the addition or removal of a permission
15 # relationship (i.e. ownership or a permission link).
17 # This also disentangles the concept of "trashed groups" from the
18 # permissions system. Updating trashed items follows a similar
19 # (but less complicated) strategy to updating permissions, so it
20 # may be helpful to look at that first.
22 ActiveRecord::Base.connection.execute "DROP MATERIALIZED VIEW IF EXISTS materialized_permission_view;"
23 drop_table :permission_refresh_lock
25 # This table stores the set of trashed groups and their trash_at
26 # time. Used to exclude trashed projects and their contents when
27 # getting object listings.
28 create_table :trashed_groups, :id => false do |t|
32 add_index :trashed_groups, :group_uuid, :unique => true
34 ActiveRecord::Base.connection.execute %{
35 create or replace function project_subtree_with_trash_at (starting_uuid varchar(27), starting_trash_at timestamp)
36 returns table (target_uuid varchar(27), trash_at timestamp)
40 /* Starting from a project, recursively traverse all the projects
41 underneath it and return a set of project uuids and trash_at times
42 (may be null). The initial trash_at can be a timestamp or null.
43 The trash_at time propagates downward to groups it owns, i.e. when a
44 group is trashed, everything underneath it in the ownership
45 hierarchy is also considered trashed. However, this is fact is
46 recorded in the trashed_groups table, not by updating trash_at field
50 project_subtree(uuid, trash_at) as (
51 values (starting_uuid, starting_trash_at)
53 select groups.uuid, LEAST(project_subtree.trash_at, groups.trash_at)
54 from groups join project_subtree on (groups.owner_uuid = project_subtree.uuid)
56 select uuid, trash_at from project_subtree;
60 # Now populate the table. For a non-test databse this is the only
61 # time this ever happens, after this the trash table is updated
62 # incrementally. See app/models/group.rb#update_trash
65 # The table to store the flattened permissions. This is almost
66 # exactly the same as the old materalized_permission_view except
67 # that the target_owner_uuid colunm in the view is now just a
68 # boolean traverse_owned (the column was only ever tested for null
71 # For details on how this table is used to apply permissions to
72 # queries, see app/models/arvados_model.rb#readable_by
74 create_table :materialized_permissions, :id => false do |t|
78 t.boolean :traverse_owned
80 add_index :materialized_permissions, [:user_uuid, :target_uuid], unique: true, name: 'permission_user_target'
81 add_index :materialized_permissions, [:target_uuid], unique: false, name: 'permission_target'
83 ActiveRecord::Base.connection.execute %{
84 create or replace function should_traverse_owned (starting_uuid varchar(27),
85 starting_perm integer)
90 /* Helper function. Determines if permission on an object implies
91 transitive permission to things the object owns. This is always
92 true for groups, but only true for users when the permission level
95 select starting_uuid like '_____-j7d0g-_______________' or
96 (starting_uuid like '_____-tpzed-_______________' and starting_perm >= 3);
100 # Merge all permission relationships into a single view. This
101 # consists of: groups owned by users and projects, users owned
102 # by other users, users have permission on themselves,
103 # and explicit permission links.
105 # A SQL view gets inlined into the query where it is used as a
106 # subquery. This enables the query planner to inject constraints,
107 # so it only has to look up edges it plans to traverse and avoid a brute
108 # force query of all edges.
109 ActiveRecord::Base.connection.execute %{
110 create view permission_graph_edges as
111 select groups.owner_uuid as tail_uuid, groups.uuid as head_uuid,
112 (3) as val, groups.uuid as edge_id from groups
114 select users.owner_uuid as tail_uuid, users.uuid as head_uuid,
115 (3) as val, users.uuid as edge_id from users
117 select users.uuid as tail_uuid, users.uuid as head_uuid,
118 (3) as val, '' as edge_id from users
120 select links.tail_uuid,
123 WHEN links.name = 'can_read' THEN 1
124 WHEN links.name = 'can_login' THEN 1
125 WHEN links.name = 'can_write' THEN 2
126 WHEN links.name = 'can_manage' THEN 3
129 links.uuid as edge_id
131 where links.link_class='permission'
134 # This is used to ensure that the permission edge passed into
135 # compute_permission_subgraph takes replaces the existing edge in
136 # the "edges" view that is about to be removed.
138 case (edges.edge_id = perm_edge_id)
139 when true then starting_perm
144 # The primary function to compute permissions for a subgraph.
145 # Comments on how it works are inline.
147 # Due to performance issues due to the query optimizer not
148 # working across function and "with" expression boundaries, I
149 # had to fall back on using string templates for repeated code
150 # in order to inline it.
152 ActiveRecord::Base.connection.execute %{
153 create or replace function compute_permission_subgraph (perm_origin_uuid varchar(27),
154 starting_uuid varchar(27),
155 starting_perm integer,
156 perm_edge_id varchar(27))
157 returns table (user_uuid varchar(27), target_uuid varchar(27), val integer, traverse_owned bool)
162 /* The purpose of this function is to compute the permissions for a
163 subgraph of the database, starting from a given edge. The newly
164 computed permissions are used to add and remove rows from the main
167 perm_origin_uuid: The object that 'gets' the permission.
169 starting_uuid: The starting object the permission applies to.
171 starting_perm: The permission that perm_origin_uuid 'has' on
172 starting_uuid One of 1, 2, 3 for can_read,
173 can_write, can_manage respectively, or 0 to revoke
176 perm_edge_id: Identifies the permission edge that is being updated.
177 Changes of ownership, this is starting_uuid.
178 For links, this is the uuid of the link object.
179 This is used to override the edge value in the database
180 with starting_perm. This is necessary when revoking
181 permissions because the update happens before edge is
185 /* Starting from starting_uuid, determine the set of objects that
186 could be affected by this permission change.
188 Note: We don't traverse users unless it is an "identity"
189 permission (permission origin is self).
191 perm_from_start(perm_origin_uuid, target_uuid, val, traverse_owned) as (
192 #{PERM_QUERY_TEMPLATE % {:base_case => %{
193 values (perm_origin_uuid, starting_uuid, starting_perm,
194 should_traverse_owned(starting_uuid, starting_perm),
195 (perm_origin_uuid = starting_uuid or starting_uuid not like '_____-tpzed-_______________'))
197 :edge_perm => edge_perm
200 /* Find other inbound edges that grant permissions to 'targets' in
201 perm_from_start, and compute permissions that originate from
204 This is necessary for two reasons:
206 1) Other users may have access to a subset of the objects
207 through other permission links than the one we started from.
208 If we don't recompute them, their permission will get dropped.
210 2) There may be more than one path through which a user gets
211 permission to an object. For example, a user owns a project
212 and also shares it can_read with a group the user belongs
213 to. adding the can_read link must not overwrite the existing
214 can_manage permission granted by ownership.
216 additional_perms(perm_origin_uuid, target_uuid, val, traverse_owned) as (
217 #{PERM_QUERY_TEMPLATE % {:base_case => %{
218 select edges.tail_uuid as origin_uuid, edges.head_uuid as target_uuid, edges.val,
219 should_traverse_owned(edges.head_uuid, edges.val),
220 edges.head_uuid like '_____-j7d0g-_______________'
221 from permission_graph_edges as edges
222 where edges.edge_id != perm_edge_id and
223 edges.tail_uuid not in (select target_uuid from perm_from_start where target_uuid like '_____-j7d0g-_______________') and
224 edges.head_uuid in (select target_uuid from perm_from_start)
226 :edge_perm => edge_perm
229 /* Combine the permissions computed in the first two phases. */
230 all_perms(perm_origin_uuid, target_uuid, val, traverse_owned) as (
231 select * from perm_from_start
233 select * from additional_perms
236 /* The actual query that produces rows to be added or removed
237 from the materialized_permissions table. This is the clever
242 * For every group, the materialized_permissions lists all users
243 that can access to that group.
245 * The all_perms subquery has computed permissions on on a set of
246 objects for all inbound "origins", which are users or groups.
248 * Permissions through groups are transitive.
252 1) The materialized_permissions table declares that user X has permission N on group Y
253 2) The all_perms result has determined group Y has permission M on object Z
254 3) Therefore, user X has permission min(N, M) on object Z
256 This allows us to efficiently determine the set of users that
257 have permissions on the subset of objects, without having to
258 follow the chain of permission back up to find those users.
260 In addition, because users always have permission on themselves, this
261 query also makes sure those permission rows are always
264 select v.user_uuid, v.target_uuid, max(v.perm_level), bool_or(v.traverse_owned) from
267 least(u.val, m.perm_level) as perm_level,
269 from all_perms as u, materialized_permissions as m
270 where u.perm_origin_uuid = m.target_uuid AND m.traverse_owned
271 AND (m.user_uuid = m.target_uuid or m.target_uuid not like '_____-tpzed-_______________')
273 select target_uuid as user_uuid, target_uuid, 3, true
275 where all_perms.target_uuid like '_____-tpzed-_______________') as v
276 group by v.user_uuid, v.target_uuid
281 # Populate materialized_permissions by traversing permissions
282 # starting at each user.
288 drop_table :materialized_permissions
289 drop_table :trashed_groups
291 ActiveRecord::Base.connection.execute "DROP function project_subtree_with_trash_at (varchar, timestamp);"
292 ActiveRecord::Base.connection.execute "DROP function compute_permission_subgraph (varchar, varchar, integer, varchar);"
293 ActiveRecord::Base.connection.execute "DROP function should_traverse_owned(varchar, integer);"
294 ActiveRecord::Base.connection.execute "DROP view permission_graph_edges;"
296 ActiveRecord::Base.connection.execute(%{
297 CREATE MATERIALIZED VIEW materialized_permission_view AS
298 WITH RECURSIVE perm_value(name, val) AS (
299 VALUES ('can_read'::text,(1)::smallint), ('can_login'::text,1), ('can_write'::text,2), ('can_manage'::text,3)
300 ), perm_edges(tail_uuid, head_uuid, val, follow, trashed) AS (
301 SELECT links.tail_uuid,
304 ((pv.val = 3) OR (groups.uuid IS NOT NULL)) AS follow,
305 (0)::smallint AS trashed,
306 (0)::smallint AS followtrash
308 LEFT JOIN perm_value pv ON ((pv.name = (links.name)::text)))
309 LEFT JOIN public.groups ON (((pv.val < 3) AND ((groups.uuid)::text = (links.head_uuid)::text))))
310 WHERE ((links.link_class)::text = 'permission'::text)
312 SELECT groups.owner_uuid,
317 WHEN ((groups.trash_at IS NOT NULL) AND (groups.trash_at < clock_timestamp())) THEN 1
322 ), perm(val, follow, user_uuid, target_uuid, trashed) AS (
323 SELECT (3)::smallint AS val,
325 (users.uuid)::character varying(32) AS user_uuid,
326 (users.uuid)::character varying(32) AS target_uuid,
327 (0)::smallint AS trashed
330 SELECT (LEAST((perm_1.val)::integer, edges.val))::smallint AS val,
333 (edges.head_uuid)::character varying(32) AS target_uuid,
334 ((GREATEST((perm_1.trashed)::integer, edges.trashed) * edges.followtrash))::smallint AS trashed
336 JOIN perm_edges edges ON ((perm_1.follow AND ((edges.tail_uuid)::text = (perm_1.target_uuid)::text))))
338 SELECT perm.user_uuid,
340 max(perm.val) AS perm_level,
342 WHEN true THEN perm.target_uuid
343 ELSE NULL::character varying
344 END AS target_owner_uuid,
345 max(perm.trashed) AS trashed
347 GROUP BY perm.user_uuid, perm.target_uuid,
349 WHEN true THEN perm.target_uuid
350 ELSE NULL::character varying
356 add_index :materialized_permission_view, [:trashed, :target_uuid], name: 'permission_target_trashed'
357 add_index :materialized_permission_view, [:user_uuid, :trashed, :perm_level], name: 'permission_target_user_trashed_level'
358 create_table :permission_refresh_lock
360 ActiveRecord::Base.connection.execute 'REFRESH MATERIALIZED VIEW materialized_permission_view;'