Fix performance issue finding snippet replicables
What does this MR do?
Improve performance of replicable queries for snippet repositories.
Relates to #287763 (closed)
Database Review
In order to make these queries work in database-lab (since gitlab.com has no geo nodes), I've replaced
SELECT "geo_node_namespace_links"."namespace_id" AS id
FROM "geo_node_namespace_links"
WHERE "geo_node_namespace_links"."geo_node_id" = 100109
with
SELECT 9970 AS id
This shouldn't take too much time from the sub-query since it's a simple id lookup, but it should be better than running it on the staging db. Since #database-lab has a cold cache.
Original Query (modified to run in #database-lab)
SELECT "snippet_repositories".*
FROM (
(
SELECT "snippet_repositories".*
FROM "snippet_repositories"
INNER JOIN "snippets" ON "snippets"."id" = "snippet_repositories"."snippet_id"
INNER JOIN "projects" ON "projects"."id" = "snippets"."project_id"
WHERE (
snippets.project_id IN(
SELECT "projects"."id"
FROM "projects"
WHERE "projects"."namespace_id" IN (
WITH RECURSIVE "base_and_descendants" AS (
(
SELECT 9970 AS id
)
UNION
(
SELECT "namespaces"."id"
FROM "namespaces",
"base_and_descendants"
WHERE "namespaces"."parent_id" = "base_and_descendants"."id"
)
)
SELECT "id"
FROM "base_and_descendants" AS "namespaces"
)
)
)
)
UNION
(
SELECT "snippet_repositories".*
FROM "snippet_repositories"
INNER JOIN "snippets" ON "snippets"."id" = "snippet_repositories"."snippet_id"
WHERE "snippet_repositories"."snippet_id" IN (
SELECT "snippets"."id"
FROM "snippets"
WHERE "snippets"."project_id" IS NULL
)
)
) snippet_repositories
WHERE "snippet_repositories"."snippet_id" BETWEEN 1 AND 14502
Time: 5.6s
Updated Query (modified to run in #database-lab)
(
SELECT "snippet_repositories".*
FROM "snippet_repositories"
WHERE "snippet_repositories"."snippet_id" IN (
SELECT "snippets"."id"
FROM "snippets"
WHERE (
snippets.project_id IN(
SELECT "projects"."id"
FROM "projects"
WHERE "projects"."namespace_id" IN (
WITH RECURSIVE "base_and_descendants" AS (
(
SELECT 9970 AS id
)
UNION
(
SELECT "namespaces"."id"
FROM "namespaces",
"base_and_descendants"
WHERE "namespaces"."parent_id" = "base_and_descendants"."id"
)
)
SELECT "id"
FROM "base_and_descendants" AS "namespaces"
)
)
)
AND "snippets"."id" BETWEEN 1 AND 14502
)
)
UNION
(
SELECT "snippet_repositories".*
FROM "snippet_repositories"
WHERE "snippet_repositories"."snippet_id" IN (
SELECT "snippets"."id"
FROM "snippets"
WHERE "snippets"."project_id" IS NULL
AND "snippets"."id" BETWEEN 1 AND 14502
)
)
Explain Analyze depesz - postgres.ai
Time: 271 ms
This should give us a query ?somewhat? faster than the original. It's still not great, but as these happen in a background query, I think it should be okay.
Does this MR meet the acceptance criteria?
Conformity
-
Changelog entry -
Documentation (if required) -
Code review guidelines -
Merge request performance guidelines -
Style guides -
Database guides -
Separation of EE specific content
Availability and Testing
-
Review and add/update tests for this feature/bug. Consider all test levels. See the Test Planning Process. -
Tested in all supported browsers -
Informed Infrastructure department of a default or new setting change, if applicable per definition of done
Security
If this MR contains changes to processing or storing of credentials or tokens, authorization and authentication methods and other items described in the security review guidelines:
-
Label as security and @ mention @gitlab-com/gl-security/appsec
-
The MR includes necessary changes to maintain consistency between UI, API, email, or other methods -
Security reports checked/validated by a reviewer from the AppSec team