Skip to content

Resolve "Query multiple group descendants at once"

What does this MR do?

Add a scope to return all descendants of a Group/Namespace.

.descendants is the logical name, but unfortunately Rails has already added a class method by this name. Instead we've added an include_self parameter to give us .self_and_descendants(include_self: false) and .self_and_descendant_ids(include_self: false).

SQL Additions

These are when we supply the include_self: false argument.

.self_and_descendants(include_self: false)

Linear

SELECT 
  "namespaces".* 
FROM 
  (
    SELECT 
      DISTINCT on(namespaces.id) namespaces.* 
    FROM 
      namespaces, 
      (
        SELECT 
          "namespaces"."id" 
        FROM 
          "namespaces" 
        WHERE 
          "namespaces"."type" = 'Group' 
          AND "namespaces"."id" IN (1,2,3)
      ) base 
    WHERE 
      (
        namespaces.traversal_ids @> ARRAY[base.id]
      ) 
      AND (namespaces.id <> base.id)
  ) namespaces
Time: 107.405 ms  
  - planning: 3.078 ms  
  - execution: 104.327 ms  
    - I/O read: 74.719 ms  
    - I/O write: 0.000 ms  
  
Shared buffers:  
  - hits: 110 (~880.00 KiB) from the buffer pool  
  - reads: 2484 (~19.40 MiB) from the OS file cache, including disk I/O  
  - dirtied: 32 (~256.00 KiB)  
  - writes: 0  

https://postgres.ai/console/gitlab/gitlab-production-tunnel-pg12/sessions/5837/commands/19859

Recursive

WITH RECURSIVE "base_and_descendants" AS (
  (
    SELECT 
      "namespaces".* 
    FROM 
      "namespaces" 
    WHERE 
      "namespaces"."type" = 'Group' 
      AND "namespaces"."parent_id" IN (
        SELECT 
          "namespaces"."id" 
        FROM 
          "namespaces" 
        WHERE 
          "namespaces"."type" = 'Group' 
          AND "namespaces"."id" IN (1,2,3)
      )
  ) 
  UNION 
    (
      SELECT 
        "namespaces".* 
      FROM 
        "namespaces", 
        "base_and_descendants" 
      WHERE 
        "namespaces"."type" = 'Group' 
        AND "namespaces"."parent_id" = "base_and_descendants"."id"
    )
) 
SELECT 
  "namespaces".* 
FROM 
  "base_and_descendants" AS "namespaces"
Time: 166.081 ms  
  - planning: 3.811 ms  
  - execution: 162.270 ms  
    - I/O read: 108.317 ms  
    - I/O write: 0.000 ms  
  
Shared buffers:  
  - hits: 25891 (~202.30 MiB) from the buffer pool  
  - reads: 3753 (~29.30 MiB) from the OS file cache, including disk I/O  
  - dirtied: 43 (~344.00 KiB)  
  - writes: 0  
  

https://postgres.ai/console/gitlab/gitlab-production-tunnel-pg12/sessions/5837/commands/19853

.self_and_descendant_ids(include_self: false)

Linear

SELECT 
  DISTINCT namespaces.id 
FROM 
  namespaces, 
  (
    SELECT 
      "namespaces"."id" 
    FROM 
      "namespaces" 
    WHERE 
      "namespaces"."type" = 'Group' 
      AND "namespaces"."id" IN (1,2,3)
  ) base 
WHERE 
  (
    namespaces.traversal_ids @> ARRAY[base.id]
  ) 
  AND (namespaces.id <> base.id)
Time: 21.357 ms  
  - planning: 0.419 ms  
  - execution: 20.938 ms  
    - I/O read: 0.000 ms  
    - I/O write: 0.000 ms  
  
Shared buffers:  
  - hits: 2591 (~20.20 MiB) from the buffer pool  
  - reads: 0 from the OS file cache, including disk I/O  
  - dirtied: 0  
  - writes: 0 

https://postgres.ai/console/gitlab/gitlab-production-tunnel-pg12/sessions/5837/commands/19860

Recursive

WITH RECURSIVE "base_and_descendants" AS (
  (
    SELECT 
      "namespaces".* 
    FROM 
      "namespaces" 
    WHERE 
      "namespaces"."type" = 'Group' 
      AND "namespaces"."parent_id" IN (
        SELECT 
          "namespaces"."id" 
        FROM 
          "namespaces" 
        WHERE 
          "namespaces"."type" = 'Group' 
          AND "namespaces"."id" IN (1,2,3)
      )
  ) 
  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"
Time: 178.460 ms  
  - planning: 4.064 ms  
  - execution: 174.396 ms  
    - I/O read: 113.829 ms  
    - I/O write: 0.000 ms  
  
Shared buffers:  
  - hits: 25891 (~202.30 MiB) from the buffer pool  
  - reads: 3753 (~29.30 MiB) from the OS file cache, including disk I/O  
  - dirtied: 43 (~344.00 KiB)  
  - writes: 0  

https://postgres.ai/console/gitlab/gitlab-production-tunnel-pg12/sessions/5837/commands/19855

How to setup and validate locally (strongly suggested)

Does this MR meet the acceptance criteria?

Conformity

Availability and Testing

Security

Does this MR contain changes to processing or storing of credentials or tokens, authorization and authentication methods or other items described in the security review guidelines? If not, then delete this Security section.

  • 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

Related to #337820 (closed)

Edited by Alex Pooley

Merge request reports

Loading