Skip to content

Commit

Permalink
Change: Optimize permission subqueries in acl_where_owned_user
Browse files Browse the repository at this point in the history
The clauses checking if a permission for a given resource exists no
longer contain the resource id. Instead the id is looked up outside the
subquery in all permissions for the given type and user gathered by the
subquery.

This improves performance for resource types with many items like
results by allowing PostgreSQL to execute the subquery only once and
reuse it instead of having to run a subquery for every resource in the
database.
  • Loading branch information
timopollmeier authored and a-h-abdelsalam committed Dec 14, 2023
1 parent 99d9958 commit 28054e8
Showing 1 changed file with 11 additions and 14 deletions.
25 changes: 11 additions & 14 deletions src/manage_acl.c
Original file line number Diff line number Diff line change
Expand Up @@ -1117,42 +1117,39 @@ acl_where_owned_user (const char *user_id, const char *user_sql,
{
gchar *clause;
clause
= g_strdup_printf ("OR EXISTS"
" (SELECT id FROM %spermissions_subject"
" WHERE resource = %ss%s.id"
" AND resource_type = '%s'"
= g_strdup_printf ("OR %ss%s.id IN"
" (SELECT resource FROM %spermissions_subject"
" WHERE resource_type = '%s'"
" AND resource_location = %i"
" AND (%s))",
with_prefix ? with_prefix : "",
type,
get->trash && strcmp (type, "task") ? "_trash" : "",
with_prefix ? with_prefix : "",
type,
get->trash ? LOCATION_TRASH : LOCATION_TABLE,
permission_or->str);

if (strcmp (type, "report") == 0)
permission_clause
= g_strdup_printf ("%s"
" OR EXISTS"
" (SELECT id FROM %spermissions_subject"
" WHERE resource = reports%s.task"
" AND resource_type = 'task'"
" OR reports%s.task IN"
" (SELECT resource FROM %spermissions_subject"
" WHERE resource_type = 'task'"
" AND (%s))",
clause,
with_prefix ? with_prefix : "",
get->trash ? "_trash" : "",
with_prefix ? with_prefix : "",
permission_or->str);
else if (strcmp (type, "result") == 0)
permission_clause
= g_strdup_printf ("%s"
" OR EXISTS"
" OR results%s.task IN"
" (SELECT id FROM %spermissions_subject"
" WHERE resource = results%s.task"
" AND resource_type = 'task'"
" WHERE resource_type = 'task'"
" AND (%s))",
clause,
with_prefix ? with_prefix : "",
get->trash ? "_trash" : "",
with_prefix ? with_prefix : "",
permission_or->str);

if ((strcmp (type, "report") == 0)
Expand Down

0 comments on commit 28054e8

Please sign in to comment.