1 # Copyright (C) The Arvados Authors. All rights reserved.
3 # SPDX-License-Identifier: AGPL-3.0
5 class MaterializedPermissionView < ActiveRecord::Migration[4.2]
7 @@idxtables = [:collections, :container_requests, :groups, :jobs, :links, :pipeline_instances, :pipeline_templates, :repositories, :users, :virtual_machines, :workflows, :logs]
12 # Construct a materialized view for permissions. This is a view which is
13 # derived from querying other tables, but is saved to a static table itself
14 # so that it can be indexed and queried efficiently without rerunning the
15 # query. The view is updated using "REFRESH MATERIALIZED VIEW" which is
16 # executed after an operation invalidates the permission graph.
19 ActiveRecord::Base.connection.execute(
20 "-- constructing perm_edges
21 -- 1. get the list of all permission links,
22 -- 2. any can_manage link or permission link to a group means permission should 'follow through'
23 -- (as a special case, can_manage links to a user grant access to everything owned by the user,
24 -- unlike can_read or can_write which only grant access to the user record)
25 -- 3. add all owner->owned relationships between groups as can_manage edges
27 -- constructing permissions
28 -- 1. base case: start with set of all users as the working set
30 -- join with edges where the tail is in the working set and 'follow' is true
31 -- produce a new working set with the head (target) of each edge
32 -- set permission to the least permission encountered on the path
33 -- propagate trashed flag down
35 CREATE MATERIALIZED VIEW materialized_permission_view AS
37 perm_value (name, val) AS (
39 ('can_read', 1::smallint),
44 perm_edges (tail_uuid, head_uuid, val, follow, trashed) AS (
45 SELECT links.tail_uuid,
48 (pv.val = 3 OR groups.uuid IS NOT NULL) AS follow,
49 0::smallint AS trashed
51 LEFT JOIN perm_value pv ON pv.name = links.name
52 LEFT JOIN groups ON pv.val<3 AND groups.uuid = links.head_uuid
53 WHERE links.link_class = 'permission'
55 SELECT owner_uuid, uuid, 3, true,
56 CASE WHEN trash_at IS NOT NULL and trash_at < clock_timestamp() THEN 1 ELSE 0 END
59 perm (val, follow, user_uuid, target_uuid, trashed) AS (
60 SELECT 3::smallint AS val,
62 users.uuid::varchar(32) AS user_uuid,
63 users.uuid::varchar(32) AS target_uuid,
64 0::smallint AS trashed
67 SELECT LEAST(perm.val, edges.val)::smallint AS val,
68 edges.follow AS follow,
69 perm.user_uuid::varchar(32) AS user_uuid,
70 edges.head_uuid::varchar(32) AS target_uuid,
71 GREATEST(perm.trashed, edges.trashed)::smallint AS trashed
73 INNER JOIN perm_edges edges
74 ON perm.follow AND edges.tail_uuid = perm.target_uuid
78 MAX(val) AS perm_level,
79 CASE follow WHEN true THEN target_uuid ELSE NULL END AS target_owner_uuid,
80 MAX(trashed) AS trashed
82 GROUP BY user_uuid, target_uuid, target_owner_uuid;
84 add_index :materialized_permission_view, [:trashed, :target_uuid], name: 'permission_target_trashed'
85 add_index :materialized_permission_view, [:user_uuid, :trashed, :perm_level], name: 'permission_target_user_trashed_level'
87 # Indexes on the other tables are essential to for the query planner to
88 # construct an efficient join with permission_view.
90 # Our default query uses "ORDER BY modified_by desc, uuid"
92 # It turns out the existing simple index on modified_by can't be used
93 # because of the additional ordering on "uuid".
95 # To be able to utilize the index, the index ordering has to match the
96 # ORDER BY clause. For more detail see:
98 # https://www.postgresql.org/docs/9.3/static/indexes-ordering.html
100 @@idxtables.each do |table|
101 ActiveRecord::Base.connection.execute("CREATE INDEX index_#{table.to_s}_on_modified_at_uuid ON #{table.to_s} USING btree (modified_at desc, uuid asc)")
104 create_table :permission_refresh_lock
105 ActiveRecord::Base.connection.execute("REFRESH MATERIALIZED VIEW materialized_permission_view")
109 drop_table :permission_refresh_lock
110 remove_index :materialized_permission_view, name: 'permission_target_trashed'
111 remove_index :materialized_permission_view, name: 'permission_target_user_trashed_level'
112 @@idxtables.each do |table|
113 ActiveRecord::Base.connection.execute("DROP INDEX IF EXISTS index_#{table.to_s}_on_modified_at_uuid")
115 ActiveRecord::Base.connection.execute("DROP MATERIALIZED VIEW IF EXISTS materialized_permission_view")