Skip to content

Conversation

Rom1-B
Copy link
Contributor

@Rom1-B Rom1-B commented Aug 7, 2025

Checklist before requesting a review

Please delete options that are not relevant.

  • I have read the CONTRIBUTING document.
  • I have performed a self-review of my code.
  • I have added tests that prove my fix is effective or that my feature works.
  • This change requires a documentation update.

Description

  • It fixes !38556

Attempts to optimize the SQL search query when performing a COUNT, especially in user-related searches. Currently, up to three searchoptions can be used to count tickets linked to a user. When the database contains a large number of tickets and multiple such columns are selected, the query consumes significant resources and can crash GLPI if it takes too long.

The issue stems from LEFT JOINs being executed before the count, forcing the database to process a large number of rows. This PR refactors the query to move the calculation into a subquery, on which the LEFT JOIN is then performed. This avoids multiplying intermediate rows and significantly reduces query overhead.

Screenshots (if appropriate):

@Rom1-B Rom1-B marked this pull request as ready for review August 11, 2025 07:13
@Rom1-B Rom1-B requested review from AdrienClairembault, cedric-anne and trasher and removed request for trasher August 11, 2025 07:13
Copy link
Contributor

@AdrienClairembault AdrienClairembault left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Seems good since no tests are broken but just looking at the code it is hard to understand what exact performances change happened.

Maybe a real example of some before/after timings of the SQL request would help us see the improvement?

A question for maintainers: I don't know if it is worth spending time on this but maybe we could setup something to keep track of the performances of a few important process?

This would make sure we don't have regression on this kind of search engine stuff that can easily break the next time it is modified (as some performances gain on a feature of the search engine can easily lead to losses for others features, we've seen it before).

A quick search show me there is this tool https://github.com/phpbench/phpbench, but I don't know if the results would be exploitable as we don't control the CI runners and they are not always equal in performances.

Edit: the runner would not be a problem as I guess we would generate the baseline on the same runner anyway and would only mesure the difference between the baseline on main and the changes from the PR, I think it can actually be setup quite easily.

@Rom1-B
Copy link
Contributor Author

Rom1-B commented Aug 12, 2025

I don’t have precise comparison timings to provide because on a small database the performance is similar, whereas on a large database with 44,000 tickets, the old SQL query didn’t complete (too slow) and the new version runs in 1 second.

Here are the columns displayed:
image

The old query directly uses COUNT(DISTINCT ...) with multiple heavy joins in the main query.
The new query pre-calculates these counts in aggregated subqueries, which significantly reduces the load and speeds up execution.

Old Query:

SELECT
  DISTINCT `glpi_users`.`id` AS id,
  'glpi' AS currentuser,
  GROUP_CONCAT(
    DISTINCT CONCAT(`glpi_users`.`name`, '$#$', `glpi_users`.`id`)
    ORDER BY
      `glpi_users`.`id` SEPARATOR '$$##$$'
  ) AS `ITEM_User_1`,
  `glpi_users`.`realname` AS `ITEM_User_34`,
  GROUP_CONCAT(
    DISTINCT CONCAT(
      IFNULL(`glpi_useremails`.`email`, '__NULL__'),
      '$#$',
      `glpi_useremails`.`id`
    )
    ORDER BY
      `glpi_useremails`.`id` SEPARATOR '$$##$$'
  ) AS `ITEM_User_5`,
  `glpi_users`.`phone` AS `ITEM_User_6`,
  `glpi_locations`.`completename` AS `ITEM_User_3`,
  `glpi_users`.`is_active` AS `ITEM_User_8`,
  COUNT(
    DISTINCT `glpi_tickets_af1042e23ce6565cfe58c6db91f84692`.`id`
  ) AS `ITEM_User_60`,
  COUNT(
    DISTINCT `glpi_tickets_b159409825aa5de567851f6f7858e693`.`id`
  ) AS `ITEM_User_61`,
  COUNT(
    DISTINCT `glpi_tickets_b1b92f6be5e70531688d870931e94a65`.`id`
  ) AS `ITEM_User_64`
FROM
  `glpi_users`
  LEFT JOIN `glpi_profiles_users` ON (
    `glpi_users`.`id` = `glpi_profiles_users`.`users_id`
  )
  LEFT JOIN `glpi_useremails` ON (`glpi_users`.`id` = `glpi_useremails`.`users_id`)
  LEFT JOIN `glpi_locations` ON (
    `glpi_users`.`locations_id` = `glpi_locations`.`id`
  )
  LEFT JOIN `glpi_tickets_users` AS `glpi_tickets_users_019878060c6d5f06cbe3c4d7c31dec24` ON (
    `glpi_users`.`id` = `glpi_tickets_users_019878060c6d5f06cbe3c4d7c31dec24`.`users_id`
    AND `glpi_tickets_users_019878060c6d5f06cbe3c4d7c31dec24`.`type` = '1'
  )
  LEFT JOIN `glpi_tickets` AS `glpi_tickets_af1042e23ce6565cfe58c6db91f84692` ON (
    `glpi_tickets_users_019878060c6d5f06cbe3c4d7c31dec24`.`tickets_id` = `glpi_tickets_af1042e23ce6565cfe58c6db91f84692`.`id`
  )
  LEFT JOIN `glpi_tickets` AS `glpi_tickets_b159409825aa5de567851f6f7858e693` ON (
    `glpi_users`.`id` = `glpi_tickets_b159409825aa5de567851f6f7858e693`.`users_id_recipient`
  )
  LEFT JOIN `glpi_tickets_users` AS `glpi_tickets_users_c6f7f58b9365babf7388e555e526efd5` ON (
    `glpi_users`.`id` = `glpi_tickets_users_c6f7f58b9365babf7388e555e526efd5`.`users_id`
    AND `glpi_tickets_users_c6f7f58b9365babf7388e555e526efd5`.`type` = '2'
  )
  LEFT JOIN `glpi_tickets` AS `glpi_tickets_b1b92f6be5e70531688d870931e94a65` ON (
    `glpi_tickets_users_c6f7f58b9365babf7388e555e526efd5`.`tickets_id` = `glpi_tickets_b1b92f6be5e70531688d870931e94a65`.`id`
  )
WHERE
  `glpi_users`.`is_deleted` = 0
GROUP BY
  `glpi_users`.`id`
ORDER BY
  `id`
LIMIT
  0, 20;

New query:

SELECT
  DISTINCT `glpi_users`.`id` AS id,
  'glpi' AS currentuser,
  GROUP_CONCAT(
    DISTINCT CONCAT(`glpi_users`.`name`, '$#$', `glpi_users`.`id`)
    ORDER BY
      `glpi_users`.`id` SEPARATOR '$$##$$'
  ) AS `ITEM_User_1`,
  `glpi_users`.`realname` AS `ITEM_User_34`,
  GROUP_CONCAT(
    DISTINCT CONCAT(
      IFNULL(`glpi_useremails`.`email`, '__NULL__'),
      '$#$',
      `glpi_useremails`.`id`
    )
    ORDER BY
      `glpi_useremails`.`id` SEPARATOR '$$##$$'
  ) AS `ITEM_User_5`,
  `glpi_users`.`phone` AS `ITEM_User_6`,
  `glpi_locations`.`completename` AS `ITEM_User_3`,
  `glpi_users`.`is_active` AS `ITEM_User_8`,
  IFNULL(
    `glpi_tickets_af1042e23ce6565cfe58c6db91f84692`.`counter`,
    '0'
  ) AS `ITEM_User_60`,
  IFNULL(
    `glpi_tickets_b159409825aa5de567851f6f7858e693`.`counter`,
    '0'
  ) AS `ITEM_User_61`,
  IFNULL(
    `glpi_tickets_b1b92f6be5e70531688d870931e94a65`.`counter`,
    '0'
  ) AS `ITEM_User_64`
FROM
  `glpi_users`
  LEFT JOIN `glpi_profiles_users` ON (
    `glpi_users`.`id` = `glpi_profiles_users`.`users_id`
  )
  LEFT JOIN `glpi_useremails` ON (`glpi_users`.`id` = `glpi_useremails`.`users_id`)
  LEFT JOIN `glpi_locations` ON (
    `glpi_users`.`locations_id` = `glpi_locations`.`id`
  )
  LEFT JOIN (
    SELECT
      `glpi_users`.`id`,
      COUNT(
        DISTINCT glpi_tickets_af1042e23ce6565cfe58c6db91f84692.id
      ) AS `counter`
    FROM
      `glpi_users`
      INNER JOIN `glpi_tickets_users` AS `glpi_tickets_users_019878060c6d5f06cbe3c4d7c31dec24` ON (
        `glpi_users`.`id` = `glpi_tickets_users_019878060c6d5f06cbe3c4d7c31dec24`.`users_id`
        AND `glpi_tickets_users_019878060c6d5f06cbe3c4d7c31dec24`.`type` = '1'
      )
      INNER JOIN `glpi_tickets` AS `glpi_tickets_af1042e23ce6565cfe58c6db91f84692` ON (
        `glpi_tickets_users_019878060c6d5f06cbe3c4d7c31dec24`.`tickets_id` = `glpi_tickets_af1042e23ce6565cfe58c6db91f84692`.`id`
      )
    GROUP BY
      `glpi_users`.`id`
  ) AS `glpi_tickets_af1042e23ce6565cfe58c6db91f84692` ON (
    `glpi_users`.`id` = `glpi_tickets_af1042e23ce6565cfe58c6db91f84692`.`id`
  )
  LEFT JOIN (
    SELECT
      `users_id_recipient`,
      COUNT(*) AS `counter`
    FROM
      `glpi_tickets`
    GROUP BY
      `users_id_recipient`
  ) AS `glpi_tickets_b159409825aa5de567851f6f7858e693` ON (
    `glpi_users`.`id` = `glpi_tickets_b159409825aa5de567851f6f7858e693`.`users_id_recipient`
  )
  LEFT JOIN (
    SELECT
      `glpi_users`.`id`,
      COUNT(
        DISTINCT glpi_tickets_b1b92f6be5e70531688d870931e94a65.id
      ) AS `counter`
    FROM
      `glpi_users`
      INNER JOIN `glpi_tickets_users` AS `glpi_tickets_users_c6f7f58b9365babf7388e555e526efd5` ON (
        `glpi_users`.`id` = `glpi_tickets_users_c6f7f58b9365babf7388e555e526efd5`.`users_id`
        AND `glpi_tickets_users_c6f7f58b9365babf7388e555e526efd5`.`type` = '2'
      )
      INNER JOIN `glpi_tickets` AS `glpi_tickets_b1b92f6be5e70531688d870931e94a65` ON (
        `glpi_tickets_users_c6f7f58b9365babf7388e555e526efd5`.`tickets_id` = `glpi_tickets_b1b92f6be5e70531688d870931e94a65`.`id`
      )
    GROUP BY
      `glpi_users`.`id`
  ) AS `glpi_tickets_b1b92f6be5e70531688d870931e94a65` ON (
    `glpi_users`.`id` = `glpi_tickets_b1b92f6be5e70531688d870931e94a65`.`id`
  )
WHERE
  `glpi_users`.`is_deleted` = 0
GROUP BY
  `glpi_users`.`id`
ORDER BY
  `id`
LIMIT
  0, 20;

@cedric-anne cedric-anne added this to the 11.1.0 milestone Aug 13, 2025
@ftoledo
Copy link

ftoledo commented Sep 12, 2025

@Rom1-B

This can be a related:
#19842

The performance difference is tremendous. Will it be possible to backport to glpi 10.x?

@Rom1-B
Copy link
Contributor Author

Rom1-B commented Sep 15, 2025

This can be a related: #19842

Yes, this is the same issue: the slowdown occurs when both the "Number of writer tickets" and "Number of tickets as requester" columns are used simultaneously. Note that no slowdown is observed when either column is used individually.

The performance difference is tremendous. Will it be possible to backport to glpi 10.x?

This patch is not compatible with GLPI 10.0. It targets the next major release because it alters the behavior of the search engine (a core and impactful feature in GLPI). However, this use case is specific and easily avoidable, which is why the fix is planned for the next major version (>11.1).

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Projects

None yet

Development

Successfully merging this pull request may close these issues.

4 participants