Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
4 changes: 2 additions & 2 deletions share-api/src/Share/Postgres/Contributions/Queries.hs
Original file line number Diff line number Diff line change
Expand Up @@ -260,10 +260,10 @@ listContributionsByUserId callerUserId userId limit mayCursor mayStatusFilter ma
contribution.author_id,
(SELECT COUNT(*) FROM comments comment WHERE comment.contribution_id = contribution.id AND comment.deleted_at IS NULL) as num_comments
FROM contributions AS contribution
JOIN projects AS project ON project.id = contribution.project_id
JOIN projects_by_user_permission(#{callerUserId}, #{ProjectView}) AS project
ON project.id = contribution.project_id
WHERE
contribution.author_id = #{userId}
AND user_has_project_permission(#{callerUserId}, project.id, #{ProjectView})
AND (#{mayStatusFilter} IS NULL OR contribution.status = #{mayStatusFilter})
AND ^{cursorFilter}
AND ^{kindFilter}
Expand Down
16 changes: 6 additions & 10 deletions share-api/src/Share/Postgres/Queries.hs
Original file line number Diff line number Diff line change
Expand Up @@ -156,22 +156,20 @@ searchProjects caller userIdFilter (Query query) psk limit = do
PG.queryListRows @(Project PG.:. PG.Only UserHandle)
[PG.sql|
SELECT p.id, p.owner_user_id, p.slug, p.summary, p.tags, p.private, p.created_at, p.updated_at, owner.handle
FROM projects p
FROM projects_by_user_permission(#{caller}, #{ProjectView}) p
JOIN users owner ON p.owner_user_id = owner.id
WHERE p.owner_user_id = #{userId}
AND user_has_project_permission(#{caller}, p.id, #{ProjectView})
ORDER BY p.created_at DESC
ORDER BY p.created_at DESC, p.slug ASC
LIMIT #{limit}
|]
_ -> do
PG.queryListRows
[PG.sql|
SELECT p.id, p.owner_user_id, p.slug, p.summary, p.tags, p.private, p.created_at, p.updated_at, owner.handle
FROM websearch_to_tsquery('english', #{query}) AS tokenquery, projects AS p
FROM websearch_to_tsquery('english', #{query}) AS tokenquery, projects_by_user_permission(#{caller}, #{ProjectView}) AS p
JOIN users AS owner ON p.owner_user_id = owner.id
WHERE (tokenquery @@ p.project_text_document OR p.slug ILIKE ('%' || like_escape(#{query}) || '%'))
AND (#{userIdFilter} IS NULL OR p.owner_user_id = #{userIdFilter})
AND user_has_project_permission(#{caller}, p.id, #{ProjectView})
^{pskFilter}
ORDER BY
p.slug = #{query} DESC,
Expand Down Expand Up @@ -275,11 +273,10 @@ listProjectsByUserWithMetadata callerUserId projectOwnerUserId = do
owner.handle,
owner.name,
EXISTS (SELECT FROM org_members WHERE org_members.organization_user_id = owner.id) AS is_org
FROM projects p
FROM projects_by_user_permission(#{callerUserId}, #{ProjectView}) AS p
JOIN users owner ON owner.id = p.owner_user_id
WHERE p.owner_user_id = #{projectOwnerUserId}
AND user_has_project_permission(#{callerUserId}, p.id, #{ProjectView})
ORDER BY p.created_at DESC
ORDER BY p.created_at DESC, p.slug ASC
|]
where
unpackRows :: [Project PG.:. FavData PG.:. ProjectOwner] -> [(Project, FavData, ProjectOwner)]
Expand Down Expand Up @@ -878,12 +875,11 @@ listContributorBranchesOfUserAccessibleToCaller contributorUserId mayCallerUserI
project_owner.name,
EXISTS (SELECT FROM org_members WHERE org_members.organization_user_id = project.owner_user_id)
FROM project_branches b
JOIN projects project ON project.id = b.project_id
JOIN projects_by_user_permission(#{mayCallerUserId}, #{ProjectView}) AS project ON project.id = b.project_id
JOIN users AS project_owner ON project_owner.id = project.owner_user_id
WHERE
b.deleted_at IS NULL
AND b.contributor_id = #{contributorUserId}
AND user_has_project_permission(#{mayCallerUserId}, b.project_id, #{ProjectView})
|],
branchNameFilter,
cursorFilter,
Expand Down
13 changes: 6 additions & 7 deletions share-api/src/Share/Postgres/Search/DefinitionSearch/Queries.hs
Original file line number Diff line number Diff line change
Expand Up @@ -401,13 +401,13 @@ globalDefNameCompletionSearch mayCaller mayUserFilter (Query query) limit = do
[sql|
WITH results(name, tag) AS (
SELECT DISTINCT doc.name, doc.tag FROM global_definition_search_docs doc
JOIN projects p ON p.id = doc.project_id
JOIN projects_by_user_permission(#{mayCaller}, #{ProjectView}) p
ON p.id = doc.project_id
WHERE
-- Find names which contain the query
doc.name ILIKE ('%.' || like_escape(#{query}) || '%')

AND user_has_project_permission(#{mayCaller}, p.id, #{ProjectView})
^{filters}
^{filters}
) SELECT r.name, r.tag FROM results r
-- Docs and tests to the bottom, then
-- prefer matches where the original query appears (case-matched),
Expand Down Expand Up @@ -501,11 +501,11 @@ globalDefinitionTokenSearch mayCaller mayUserFilter limit searchTokens preferred
queryListRows @(ProjectId, ReleaseId, Name, Hasql.Jsonb)
[sql|
SELECT doc.project_id, doc.release_id, doc.name, doc.metadata FROM global_definition_search_docs doc
JOIN projects p ON p.id = doc.project_id
JOIN projects_by_user_permission(#{mayCaller}, #{ProjectView}) p
ON p.id = doc.project_id
WHERE
-- match on search tokens using GIN index.
tsquery(#{tsQueryText}) @@ doc.search_tokens
AND user_has_project_permission(#{mayCaller}, p.id, #{ProjectView})
AND (#{preferredArity} IS NULL OR doc.arity >= #{preferredArity})
^{filters}
^{namesFilter}
Expand Down Expand Up @@ -619,11 +619,10 @@ globalDefinitionNameSearch mayCaller mayUserFilter limit (Query query) = do
queryListRows @(ProjectId, ReleaseId, Name, Hasql.Jsonb)
[sql|
SELECT doc.project_id, doc.release_id, doc.name, doc.metadata FROM global_definition_search_docs doc
JOIN projects p ON p.id = doc.project_id
JOIN projects_by_user_permission(#{mayCaller}, #{ProjectView}) p ON p.id = doc.project_id
WHERE
-- We may wish to adjust the similarity threshold before the query.
#{query} <% doc.name
AND user_has_project_permission(#{mayCaller}, p.id, #{ProjectView})
^{filters}
-- Score matches by:
-- - projects in the catalog
Expand Down
3 changes: 1 addition & 2 deletions share-api/src/Share/Postgres/Tickets/Queries.hs
Original file line number Diff line number Diff line change
Expand Up @@ -251,10 +251,9 @@ listTicketsByUserId callerUserId userId limit mayCursor mayStatusFilter = do
ticket.author_id,
(SELECT COUNT(*) FROM comments comment WHERE comment.ticket_id = ticket.id AND comment.deleted_at IS NULL) as num_comments
FROM tickets AS ticket
JOIN projects AS project ON project.id = ticket.project_id
JOIN projects_by_user_permission(#{callerUserId}, #{ProjectView}) AS project ON project.id = ticket.project_id
WHERE
ticket.author_id = #{userId}
AND user_has_project_permission(#{callerUserId}, project.id, #{ProjectView})
AND (#{mayStatusFilter} IS NULL OR ticket.status = #{mayStatusFilter}::ticket_status)
AND ^{cursorFilter}
ORDER BY ticket.updated_at DESC, ticket.id DESC
Expand Down
45 changes: 45 additions & 0 deletions sql/2025-12-15_faster-project-by-permissions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
-- The previous user_has_project_permission function is called on _every_ project when doing global omnisearch,
-- which is too slow.

-- Create a view which serves as join table for finding projects for which the user has a given permission, it's much faster
-- than running a permission check for every private project when we need to discover the list of all projects a user
-- has access to.
--
-- This special-cases the 'project:view' permission to be even faster, it's the most common case.
CREATE FUNCTION projects_by_user_permission(arg_user_id UUID, arg_permission permission)
-- Returns a subset of the projects table
RETURNS SETOF projects AS $$
-- Get all public projects and projects owned by the user,
-- as well as all public projects.
SELECT p.*
FROM projects p
WHERE p.owner_user_id = arg_user_id
OR (arg_permission = 'project:view' AND NOT p.private)
UNION
SELECT
p.*
FROM org_members om
JOIN projects p
ON om.organization_user_id = p.owner_user_id
JOIN roles r ON om.role_id = r.id
WHERE om.member_user_id = arg_user_id
AND arg_permission = ANY(r.permissions)
-- All public projects are already included above if the permission is 'project:view'
AND (p.private OR arg_permission <> 'project:view')
UNION
-- Include projects the user is a direct maintainer of
SELECT
p.*
FROM users u
JOIN role_memberships rm ON u.subject_id = rm.subject_id
JOIN roles r ON rm.role_id = r.id
JOIN projects p ON rm.resource_id = p.resource_id
WHERE u.id = arg_user_id
AND arg_permission = ANY(r.permissions)
-- All public projects are already included above if the permission is 'project:view'
AND (p.private OR arg_permission <> 'project:view')
$$ LANGUAGE sql STABLE PARALLEL SAFE;

-- A better index for this query.
CREATE INDEX idx_projects_by_owner_and_privacy
ON projects (private, owner_user_id);
Original file line number Diff line number Diff line change
Expand Up @@ -3,32 +3,32 @@
{
"createdAt": "<TIMESTAMP>",
"isFaved": false,
"numFavs": 1,
"numFavs": 0,
"owner": {
"handle": "@test",
"name": null,
"type": "user"
},
"slug": "publictestproject",
"summary": "test project summary",
"slug": "privatetestproject",
"summary": "private summary",
"tags": [],
"updatedAt": "<TIMESTAMP>",
"visibility": "public"
"visibility": "private"
},
{
"createdAt": "<TIMESTAMP>",
"isFaved": false,
"numFavs": 0,
"numFavs": 1,
"owner": {
"handle": "@test",
"name": null,
"type": "user"
},
"slug": "privatetestproject",
"summary": "private summary",
"slug": "publictestproject",
"summary": "test project summary",
"tags": [],
"updatedAt": "<TIMESTAMP>",
"visibility": "private"
"visibility": "public"
}
],
"status": [
Expand Down
Loading