Skip to content

Add filtering vulnerabilities for autocomplete in Vulnerabilities Finder

What does this MR do?

Related to #222483 (closed)

This change adds Autocomplete::VulnerabilitiesFinder to fetch vulnerabilities that are accessible by the user, limited by 5 and where query matches ID or Title.

Queries

vulnerable is a Project

SELECT "vulnerabilities"."id",
  "vulnerabilities"."title"
FROM "vulnerabilities"
WHERE "vulnerabilities"."project_id" = 278964
  AND (
    "vulnerabilities"."title" ILIKE '%password%'
    OR CAST("vulnerabilities"."id" AS TEXT) ILIKE '%password%'
  )
  AND "vulnerabilities"."project_id" IN (
    SELECT "projects"."id"
    FROM "projects"
    WHERE "projects"."id" IN (
        SELECT "projects"."id"
        FROM "projects"
          INNER JOIN "project_authorizations" ON "projects"."id" = "project_authorizations"."project_id"
        WHERE "project_authorizations"."user_id" = 5535431
          AND (project_authorizations.access_level >= 30)
      )
  )
ORDER BY "vulnerabilities"."id" DESC
LIMIT 5;

https://explain.depesz.com/s/IqoP (~20ms)

vulnerable is a Group

SELECT "vulnerabilities"."id",
  "vulnerabilities"."title"
FROM "vulnerabilities"
WHERE "vulnerabilities"."project_id" IN (
    SELECT "projects"."id"
    FROM "projects"
    WHERE "projects"."namespace_id" IN (
        WITH RECURSIVE "base_and_descendants" AS (
          (
            SELECT "namespaces".*
            FROM "namespaces"
            WHERE "namespaces"."type" = 'Group'
              AND "namespaces"."id" = 9970
          )
          UNION
          (
            SELECT "namespaces".*
            FROM "namespaces",
              "base_and_descendants"
            WHERE "namespaces"."type" = 'Group'
              AND "namespaces"."parent_id" = "base_and_descendants"."id"
          )
        )
        SELECT "id"
        FROM "base_and_descendants" AS "namespaces"
      )
      AND "projects"."archived" = FALSE
      AND "projects"."pending_delete" = FALSE
  )
  AND (
    "vulnerabilities"."title" ILIKE '%password%'
    OR CAST("vulnerabilities"."id" AS TEXT) ILIKE '%password%'
  )
  AND "vulnerabilities"."project_id" IN (
    SELECT "projects"."id"
    FROM "projects"
    WHERE "projects"."id" IN (
        SELECT "projects"."id"
        FROM "projects"
          INNER JOIN "project_authorizations" ON "projects"."id" = "project_authorizations"."project_id"
        WHERE "project_authorizations"."user_id" = 5535431
          AND (project_authorizations.access_level >= 30)
      )
  )
ORDER BY "vulnerabilities"."id" DESC
LIMIT 5;

https://explain.depesz.com/s/F1qx2 (~22ms)

Does this MR meet the acceptance criteria?

Conformity

Availability and Testing

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
Edited by Alan (Maciej) Paruszewski

Merge request reports