[ARVADOS] updated: 1.3.0-2550-g44d11cad1

Git user git at public.arvados.org
Thu May 21 21:29:27 UTC 2020


Summary of changes:
 .../db/migrate/20200501150153_permission_table.rb  |  68 +++++------
 services/api/db/structure.sql                      | 134 ++++++++++-----------
 services/api/lib/refresh_permission_view.rb        |   4 +
 3 files changed, 98 insertions(+), 108 deletions(-)

       via  44d11cad171338c95692fe4f90644845df750632 (commit)
      from  aeeb2ebf8ef0b43177f37586204b91716fdddbc5 (commit)

Those revisions listed above that are new to this repository have
not appeared on any other notification email; so we list those
revisions in full, below.


commit 44d11cad171338c95692fe4f90644845df750632
Author: Peter Amstutz <peter.amstutz at curii.com>
Date:   Thu May 21 17:23:01 2020 -0400

    16007: Improve performance of compute_permission_subgraph
    
    Arvados-DCO-1.1-Signed-off-by: Peter Amstutz <peter.amstutz at curii.com>

diff --git a/services/api/db/migrate/20200501150153_permission_table.rb b/services/api/db/migrate/20200501150153_permission_table.rb
index cb601e3f0..89cfdbf7d 100644
--- a/services/api/db/migrate/20200501150153_permission_table.rb
+++ b/services/api/db/migrate/20200501150153_permission_table.rb
@@ -61,28 +61,22 @@ select starting_uuid like '_____-j7d0g-_______________' or
 $$;
 }
 
-
     ActiveRecord::Base.connection.execute %{
-create or replace function permission_graph_edges ()
-  returns table (tail_uuid varchar(27), head_uuid varchar(27), val integer)
-STABLE
-language SQL
-as $$
-           select groups.owner_uuid, groups.uuid, (3) from groups
-          union
-            select users.owner_uuid, users.uuid, (3) from users
-          union
-            select links.tail_uuid,
-                   links.head_uuid,
-                   CASE
-                     WHEN links.name = 'can_read'   THEN 1
-                     WHEN links.name = 'can_login'  THEN 1
-                     WHEN links.name = 'can_write'  THEN 2
-                     WHEN links.name = 'can_manage' THEN 3
-                   END as val
-          from links
-          where links.link_class='permission'
-$$;
+create view permission_graph_edges as
+  select groups.owner_uuid as tail_uuid, groups.uuid as head_uuid, (3) as val from groups
+union all
+  select users.owner_uuid as tail_uuid, users.uuid as head_uuid, (3) as val from users
+union all
+  select links.tail_uuid,
+         links.head_uuid,
+         CASE
+           WHEN links.name = 'can_read'   THEN 1
+           WHEN links.name = 'can_login'  THEN 1
+           WHEN links.name = 'can_write'  THEN 2
+           WHEN links.name = 'can_manage' THEN 3
+          END as val
+      from links
+      where links.link_class='permission'
 }
 
         # Get a set of permission by searching the graph and following
@@ -102,9 +96,7 @@ create or replace function search_permission_graph (starting_uuid varchar(27),
 STABLE
 language SQL
 as $$
-WITH RECURSIVE edges(tail_uuid, head_uuid, val) as (
-          select * from permission_graph_edges()
-        ),
+WITH RECURSIVE
         traverse_graph(target_uuid, val, traverse_owned) as (
             values (starting_uuid, starting_perm,
                     should_traverse_owned(starting_uuid, starting_perm))
@@ -116,10 +108,10 @@ WITH RECURSIVE edges(tail_uuid, head_uuid, val) as (
                             else 0
                           end),
                     should_traverse_owned(edges.head_uuid, edges.val)
-             from edges
-             join traverse_graph on (traverse_graph.target_uuid = edges.tail_uuid)))
+             from permission_graph_edges as edges, traverse_graph
+             where traverse_graph.target_uuid = edges.tail_uuid))
         select target_uuid, max(val), bool_or(traverse_owned) from traverse_graph
-        group by (target_uuid) ;
+        group by (target_uuid);
 $$;
 }
 
@@ -136,13 +128,10 @@ perm_from_start(perm_origin_uuid, target_uuid, val, traverse_owned) as (
   select perm_origin_uuid, target_uuid, val, traverse_owned
     from search_permission_graph(starting_uuid, starting_perm)),
 
-  edges(tail_uuid, head_uuid, val) as (
-        select * from permission_graph_edges()),
-
   additional_perms(perm_origin_uuid, target_uuid, val, traverse_owned) as (
     select edges.tail_uuid as perm_origin_uuid, ps.target_uuid, ps.val,
            should_traverse_owned(ps.target_uuid, ps.val)
-      from edges, lateral search_permission_graph(edges.head_uuid, edges.val) as ps
+      from permission_graph_edges as edges, lateral search_permission_graph(edges.head_uuid, edges.val) as ps
       where (not (edges.tail_uuid = perm_origin_uuid and
                  edges.head_uuid = starting_uuid)) and
             edges.tail_uuid not in (select target_uuid from perm_from_start) and
@@ -150,7 +139,7 @@ perm_from_start(perm_origin_uuid, target_uuid, val, traverse_owned) as (
 
   partial_perms(perm_origin_uuid, target_uuid, val, traverse_owned) as (
       select * from perm_from_start
-    union
+    union all
       select * from additional_perms
   ),
 
@@ -169,17 +158,16 @@ perm_from_start(perm_origin_uuid, target_uuid, val, traverse_owned) as (
   )
 
   select v.user_uuid, v.target_uuid, max(v.perm_level), bool_or(v.traverse_owned) from
-    (select materialized_permissions.user_uuid,
+    (select m.user_uuid,
          u.target_uuid,
-         least(u.val, materialized_permissions.perm_level) as perm_level,
+         least(u.val, m.perm_level) as perm_level,
          u.traverse_owned
-      from all_perms as u
-      join materialized_permissions on (u.perm_origin_uuid = materialized_permissions.target_uuid)
-      where materialized_permissions.traverse_owned
-    union
+      from all_perms as u, materialized_permissions as m
+           where u.perm_origin_uuid = m.target_uuid AND m.traverse_owned
+    union all
       select perm_origin_uuid as user_uuid, target_uuid, val as perm_level, traverse_owned
         from all_perms
-        where perm_origin_uuid like '_____-tpzed-_______________') as v
+        where all_perms.perm_origin_uuid like '_____-tpzed-_______________') as v
     group by v.user_uuid, v.target_uuid
 $$;
      }
@@ -200,7 +188,7 @@ from users, lateral search_permission_graph(users.uuid, 3) as g where g.val > 0
     ActiveRecord::Base.connection.execute "DROP function search_permission_graph(varchar, integer);"
     ActiveRecord::Base.connection.execute "DROP function compute_permission_subgraph (varchar, varchar, integer);"
     ActiveRecord::Base.connection.execute "DROP function should_traverse_owned(varchar, integer);"
-    ActiveRecord::Base.connection.execute "DROP function permission_graph_edges();"
+    ActiveRecord::Base.connection.execute "DROP view permission_graph_edges;"
 
     ActiveRecord::Base.connection.execute(%{
 CREATE MATERIALIZED VIEW materialized_permission_view AS
diff --git a/services/api/db/structure.sql b/services/api/db/structure.sql
index fd3044e55..5f71554ff 100644
--- a/services/api/db/structure.sql
+++ b/services/api/db/structure.sql
@@ -50,13 +50,10 @@ perm_from_start(perm_origin_uuid, target_uuid, val, traverse_owned) as (
   select perm_origin_uuid, target_uuid, val, traverse_owned
     from search_permission_graph(starting_uuid, starting_perm)),
 
-  edges(tail_uuid, head_uuid, val) as (
-        select * from permission_graph_edges()),
-
   additional_perms(perm_origin_uuid, target_uuid, val, traverse_owned) as (
     select edges.tail_uuid as perm_origin_uuid, ps.target_uuid, ps.val,
            should_traverse_owned(ps.target_uuid, ps.val)
-      from edges, lateral search_permission_graph(edges.head_uuid, edges.val) as ps
+      from permission_graph_edges as edges, lateral search_permission_graph(edges.head_uuid, edges.val) as ps
       where (not (edges.tail_uuid = perm_origin_uuid and
                  edges.head_uuid = starting_uuid)) and
             edges.tail_uuid not in (select target_uuid from perm_from_start) and
@@ -64,7 +61,7 @@ perm_from_start(perm_origin_uuid, target_uuid, val, traverse_owned) as (
 
   partial_perms(perm_origin_uuid, target_uuid, val, traverse_owned) as (
       select * from perm_from_start
-    union
+    union all
       select * from additional_perms
   ),
 
@@ -83,17 +80,16 @@ perm_from_start(perm_origin_uuid, target_uuid, val, traverse_owned) as (
   )
 
   select v.user_uuid, v.target_uuid, max(v.perm_level), bool_or(v.traverse_owned) from
-    (select materialized_permissions.user_uuid,
+    (select m.user_uuid,
          u.target_uuid,
-         least(u.val, materialized_permissions.perm_level) as perm_level,
+         least(u.val, m.perm_level) as perm_level,
          u.traverse_owned
-      from all_perms as u
-      join materialized_permissions on (u.perm_origin_uuid = materialized_permissions.target_uuid)
-      where materialized_permissions.traverse_owned
-    union
+      from all_perms as u, materialized_permissions as m
+           where u.perm_origin_uuid = m.target_uuid AND m.traverse_owned
+    union all
       select perm_origin_uuid as user_uuid, target_uuid, val as perm_level, traverse_owned
         from all_perms
-        where perm_origin_uuid like '_____-tpzed-_______________') as v
+        where all_perms.perm_origin_uuid like '_____-tpzed-_______________') as v
     group by v.user_uuid, v.target_uuid
 $$;
 
@@ -111,30 +107,6 @@ select ps.target_uuid as group_uuid, ps.trash_at from groups,
 $$;
 
 
---
--- Name: permission_graph_edges(); Type: FUNCTION; Schema: public; Owner: -
---
-
-CREATE FUNCTION public.permission_graph_edges() RETURNS TABLE(tail_uuid character varying, head_uuid character varying, val integer)
-    LANGUAGE sql STABLE
-    AS $$
-           select groups.owner_uuid, groups.uuid, (3) from groups
-          union
-            select users.owner_uuid, users.uuid, (3) from users
-          union
-            select links.tail_uuid,
-                   links.head_uuid,
-                   CASE
-                     WHEN links.name = 'can_read'   THEN 1
-                     WHEN links.name = 'can_login'  THEN 1
-                     WHEN links.name = 'can_write'  THEN 2
-                     WHEN links.name = 'can_manage' THEN 3
-                   END as val
-          from links
-          where links.link_class='permission'
-$$;
-
-
 --
 -- Name: project_subtree_with_trash_at(character varying, timestamp without time zone); Type: FUNCTION; Schema: public; Owner: -
 --
@@ -160,9 +132,7 @@ $$;
 CREATE FUNCTION public.search_permission_graph(starting_uuid character varying, starting_perm integer) RETURNS TABLE(target_uuid character varying, val integer, traverse_owned boolean)
     LANGUAGE sql STABLE
     AS $$
-WITH RECURSIVE edges(tail_uuid, head_uuid, val) as (
-          select * from permission_graph_edges()
-        ),
+WITH RECURSIVE
         traverse_graph(target_uuid, val, traverse_owned) as (
             values (starting_uuid, starting_perm,
                     should_traverse_owned(starting_uuid, starting_perm))
@@ -174,10 +144,10 @@ WITH RECURSIVE edges(tail_uuid, head_uuid, val) as (
                             else 0
                           end),
                     should_traverse_owned(edges.head_uuid, edges.val)
-             from edges
-             join traverse_graph on (traverse_graph.target_uuid = edges.tail_uuid)))
+             from permission_graph_edges as edges, traverse_graph
+             where traverse_graph.target_uuid = edges.tail_uuid))
         select target_uuid, max(val), bool_or(traverse_owned) from traverse_graph
-        group by (target_uuid) ;
+        group by (target_uuid);
 $$;
 
 
@@ -929,6 +899,60 @@ CREATE SEQUENCE public.nodes_id_seq
 ALTER SEQUENCE public.nodes_id_seq OWNED BY public.nodes.id;
 
 
+--
+-- Name: users; Type: TABLE; Schema: public; Owner: -
+--
+
+CREATE TABLE public.users (
+    id integer NOT NULL,
+    uuid character varying(255),
+    owner_uuid character varying(255) NOT NULL,
+    created_at timestamp without time zone NOT NULL,
+    modified_by_client_uuid character varying(255),
+    modified_by_user_uuid character varying(255),
+    modified_at timestamp without time zone,
+    email character varying(255),
+    first_name character varying(255),
+    last_name character varying(255),
+    identity_url character varying(255),
+    is_admin boolean,
+    prefs text,
+    updated_at timestamp without time zone NOT NULL,
+    default_owner_uuid character varying(255),
+    is_active boolean DEFAULT false,
+    username character varying(255),
+    redirect_to_user_uuid character varying
+);
+
+
+--
+-- Name: permission_graph_edges; Type: VIEW; Schema: public; Owner: -
+--
+
+CREATE VIEW public.permission_graph_edges AS
+ SELECT groups.owner_uuid AS tail_uuid,
+    groups.uuid AS head_uuid,
+    3 AS val
+   FROM public.groups
+UNION ALL
+ SELECT users.owner_uuid AS tail_uuid,
+    users.uuid AS head_uuid,
+    3 AS val
+   FROM public.users
+UNION ALL
+ SELECT links.tail_uuid,
+    links.head_uuid,
+        CASE
+            WHEN ((links.name)::text = 'can_read'::text) THEN 1
+            WHEN ((links.name)::text = 'can_login'::text) THEN 1
+            WHEN ((links.name)::text = 'can_write'::text) THEN 2
+            WHEN ((links.name)::text = 'can_manage'::text) THEN 3
+            ELSE NULL::integer
+        END AS val
+   FROM public.links
+  WHERE ((links.link_class)::text = 'permission'::text);
+
+
 --
 -- Name: pipeline_instances; Type: TABLE; Schema: public; Owner: -
 --
@@ -1140,32 +1164,6 @@ CREATE TABLE public.trashed_groups (
 );
 
 
---
--- Name: users; Type: TABLE; Schema: public; Owner: -
---
-
-CREATE TABLE public.users (
-    id integer NOT NULL,
-    uuid character varying(255),
-    owner_uuid character varying(255) NOT NULL,
-    created_at timestamp without time zone NOT NULL,
-    modified_by_client_uuid character varying(255),
-    modified_by_user_uuid character varying(255),
-    modified_at timestamp without time zone,
-    email character varying(255),
-    first_name character varying(255),
-    last_name character varying(255),
-    identity_url character varying(255),
-    is_admin boolean,
-    prefs text,
-    updated_at timestamp without time zone NOT NULL,
-    default_owner_uuid character varying(255),
-    is_active boolean DEFAULT false,
-    username character varying(255),
-    redirect_to_user_uuid character varying
-);
-
-
 --
 -- Name: users_id_seq; Type: SEQUENCE; Schema: public; Owner: -
 --
diff --git a/services/api/lib/refresh_permission_view.rb b/services/api/lib/refresh_permission_view.rb
index 1587f7fec..3901a1f22 100644
--- a/services/api/lib/refresh_permission_view.rb
+++ b/services/api/lib/refresh_permission_view.rb
@@ -42,6 +42,8 @@ def update_permissions perm_origin_uuid, starting_uuid, perm_level, check=false
 
   ActiveRecord::Base.connection.execute "LOCK TABLE #{PERMISSION_VIEW} in SHARE MODE"
 
+  ActiveRecord::Base.connection.exec_query "SET LOCAL enable_mergejoin to false;"
+
   temptable_perms = "temp_perms_#{rand(2**64).to_s(10)}"
   ActiveRecord::Base.connection.exec_query %{
 create temporary table #{temptable_perms} on commit drop
@@ -52,6 +54,8 @@ as select * from compute_permission_subgraph($1, $2, $3)
                                             [nil, starting_uuid],
                                             [nil, perm_level]]
 
+  ActiveRecord::Base.connection.exec_query "SET LOCAL enable_mergejoin to true;"
+
   ActiveRecord::Base.connection.exec_delete %{
 delete from #{PERMISSION_VIEW} where
   target_uuid in (select target_uuid from #{temptable_perms}) and

-----------------------------------------------------------------------


hooks/post-receive
-- 




More information about the arvados-commits mailing list