Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Optimize(Search): use LEFT JOIN filter on SELECT statement for Consumable #17078

Merged
merged 6 commits into from May 15, 2024

Conversation

stonebuzz
Copy link
Contributor

@stonebuzz stonebuzz commented May 6, 2024

From the list of Consumable, using the following search filters together causes data to load slowly

  • Number of new consumables
  • Number of used consumables

This simple SQL statement

SELECT DISTINCT `glpi_consumableitems`.`id` AS id,
         'sdb.glpi' AS currentuser,
         `glpi_consumableitems`.`entities_id`,
         `glpi_consumableitems`.`is_recursive`,
         `glpi_consumableitems`.`name` AS `ITEM_ConsumableItem_1`,
         `glpi_consumableitems`.`id` AS `ITEM_ConsumableItem_1_id`,
         `glpi_entities`.`completename` AS `ITEM_ConsumableItem_80`,
         `glpi_consumableitems`.`ref` AS `ITEM_ConsumableItem_34`,
         `glpi_consumableitemtypes`.`name` AS `ITEM_ConsumableItem_4`,
         `glpi_manufacturers`.`name` AS `ITEM_ConsumableItem_23`,
         `glpi_locations`.`completename` AS `ITEM_ConsumableItem_3`,
         `glpi_consumableitems`.`otherserial` AS `ITEM_ConsumableItem_6`
FROM `glpi_consumableitems`
LEFT JOIN `glpi_locations`
    ON (`glpi_consumableitems`.`locations_id` = `glpi_locations`.`id` )
LEFT JOIN `glpi_manufacturers`
    ON (`glpi_consumableitems`.`manufacturers_id` = `glpi_manufacturers`.`id` )
LEFT JOIN `glpi_consumableitemtypes`
    ON (`glpi_consumableitems`.`consumableitemtypes_id` = `glpi_consumableitemtypes`.`id` )
LEFT JOIN `glpi_entities`
    ON (`glpi_consumableitems`.`entities_id` = `glpi_entities`.`id` )
LEFT JOIN `glpi_consumables` AS `glpi_consumables_3a1bfaeb0a6ab317f573339b5c25c067`
    ON (`glpi_consumableitems`.`id` = `glpi_consumables_3a1bfaeb0a6ab317f573339b5c25c067`.`consumableitems_id`
        AND `glpi_consumables_3a1bfaeb0a6ab317f573339b5c25c067`.`date_out` IS NOT NULL )
LEFT JOIN `glpi_consumables` AS `glpi_consumables_316f6947f90715a8c7f2428ba032b363`
    ON (`glpi_consumableitems`.`id` = `glpi_consumables_316f6947f90715a8c7f2428ba032b363`.`consumableitems_id`
        AND `glpi_consumables_316f6947f90715a8c7f2428ba032b363`.`date_out` IS NULL )
WHERE `glpi_consumableitems`.`is_deleted` = 0
GROUP BY  `glpi_consumableitems`.`id`
ORDER BY  `ITEM_ConsumableItem_1` ASC LIMIT 0, 50

Takes almost 1 min 11,978 sec to return the results (42 rows)

42 rows in set (1 min 11,978 sec)

Here is an EXPLAIN of this SQL query

+------+-------------+---------------------------------------------------+------------+-----------------------------+-----------------------------+---------+--------------------------------------------------------+-----------+----------------------------------------------+
| id   | select_type | table                                             | type       | possible_keys               | key                         | key_len | ref                                                    | rows      | Extra                                        |
+------+-------------+---------------------------------------------------+------------+-----------------------------+-----------------------------+---------+--------------------------------------------------------+-----------+----------------------------------------------+
|    1 | SIMPLE      | glpi_consumableitems                              | index      | is_deleted                  | PRIMARY                     | 4       | NULL                                                   | 63        | Using where; Using temporary; Using filesort |
|    1 | SIMPLE      | glpi_locations                                    | eq_ref     | PRIMARY                     | PRIMARY                     | 4       | 10bugfixes.glpi_consumableitems.locations_id           | 1         |                                              |
|    1 | SIMPLE      | glpi_manufacturers                                | eq_ref     | PRIMARY                     | PRIMARY                     | 4       | 10bugfixes.glpi_consumableitems.manufacturers_id       | 1         |                                              |
|    1 | SIMPLE      | glpi_consumableitemtypes                          | eq_ref     | PRIMARY                     | PRIMARY                     | 4       | 10bugfixes.glpi_consumableitems.consumableitemtypes_id | 1         |                                              |
|    1 | SIMPLE      | glpi_entities                                     | eq_ref     | PRIMARY                     | PRIMARY                     | 4       | 10bugfixes.glpi_consumableitems.entities_id            | 1         |                                              |
|    1 | SIMPLE      | glpi_consumables_3a1bfaeb0a6ab317f573339b5c25c067 | ref|filter | date_out,consumableitems_id | consumableitems_id|date_out | 4|4     | 10bugfixes.glpi_consumableitems.id                     | 354 (50%) | Using where; Using rowid filter              |
|    1 | SIMPLE      | glpi_consumables_316f6947f90715a8c7f2428ba032b363 | ref|filter | date_out,consumableitems_id | consumableitems_id|date_out | 4|4     | 10bugfixes.glpi_consumableitems.id                     | 354 (34%) | Using where; Using rowid filter              |
+------+-------------+---------------------------------------------------+------------+-----------------------------+-----------------------------+---------+--------------------------------------------------------+-----------+----------------------------------------------+

⚠️ note that using either column (separately) works very quickly

  • Number of new consumables -> 42 rows in set (0,037 sec)
  • Number of used consumables -> 42 rows in set (0,058 sec)

The double left join on the glpi_consumables table seems to be the cause

But as this is not my area of expertise, I can't say why

  • the indexes are there,
  • the voumetry is not excessive (glpi_consumables -> 39652, glpi_consumableitems -> 63 )

To try and optimise this SQL query, I decided to deport the filter included in the LEFT JOIN directly into the SELECT statement

SELECT DISTINCT `glpi_consumableitems`.`id` AS id,
         'sdb.glpi' AS currentuser,
         `glpi_consumableitems`.`entities_id`,
         `glpi_consumableitems`.`is_recursive`,
         `glpi_consumableitems`.`name` AS `ITEM_ConsumableItem_1`,
         `glpi_consumableitems`.`id` AS `ITEM_ConsumableItem_1_id`,
         `glpi_entities`.`completename` AS `ITEM_ConsumableItem_80`,
         `glpi_consumableitems`.`ref` AS `ITEM_ConsumableItem_34`,
         `glpi_consumableitemtypes`.`name` AS `ITEM_ConsumableItem_4`,
         `glpi_manufacturers`.`name` AS `ITEM_ConsumableItem_23`,
         `glpi_locations`.`completename` AS `ITEM_ConsumableItem_3`,
         `glpi_consumableitems`.`otherserial` AS `ITEM_ConsumableItem_6`,
         SUM(case when `glpi_consumables_3a1bfaeb0a6ab317f573339b5c25c067`.`date_out` is null then 1 else 0 end) AS `ITEM_ConsumableItem_17`,
         SUM(case when `glpi_consumables_3a1bfaeb0a6ab317f573339b5c25c067`.`date_out` is not null then 1 else 0 end) AS `ITEM_ConsumableItem_18`
FROM `glpi_consumableitems`LEFT
JOIN `glpi_locations`
    ON (`glpi_consumableitems`.`locations_id` = `glpi_locations`.`id` )
LEFT JOIN `glpi_manufacturers`
    ON (`glpi_consumableitems`.`manufacturers_id` = `glpi_manufacturers`.`id` )
LEFT JOIN `glpi_consumableitemtypes`
    ON (`glpi_consumableitems`.`consumableitemtypes_id` = `glpi_consumableitemtypes`.`id` )
LEFT JOIN `glpi_entities`
    ON (`glpi_consumableitems`.`entities_id` = `glpi_entities`.`id` )
LEFT JOIN `glpi_consumables` AS `glpi_consumables_3a1bfaeb0a6ab317f573339b5c25c067`
    ON (`glpi_consumableitems`.`id` = `glpi_consumables_3a1bfaeb0a6ab317f573339b5c25c067`.`consumableitems_id`)
WHERE `glpi_consumableitems`.`is_deleted` = 0
GROUP BY  `glpi_consumableitems`.`id`
ORDER BY  `ITEM_ConsumableItem_1` ASC LIMIT 0, 50

This optimized SQL query takes almost 0,041 sec to return the results (42 rows) 👍

42 rows in set (0,041 sec)

Here is an EXPLAIN of this optimized SQL query

+------+-------------+---------------------------------------------------+--------+--------------------+--------------------+---------+--------------------------------------------------------+------+----------------------------------------------+
| id   | select_type | table                                             | type   | possible_keys      | key                | key_len | ref                                                    | rows | Extra                                        |
+------+-------------+---------------------------------------------------+--------+--------------------+--------------------+---------+--------------------------------------------------------+------+----------------------------------------------+
|    1 | SIMPLE      | glpi_consumableitems                              | index  | is_deleted         | PRIMARY            | 4       | NULL                                                   | 63   | Using where; Using temporary; Using filesort |
|    1 | SIMPLE      | glpi_locations                                    | eq_ref | PRIMARY            | PRIMARY            | 4       | 10bugfixes.glpi_consumableitems.locations_id           | 1    |                                              |
|    1 | SIMPLE      | glpi_manufacturers                                | eq_ref | PRIMARY            | PRIMARY            | 4       | 10bugfixes.glpi_consumableitems.manufacturers_id       | 1    |                                              |
|    1 | SIMPLE      | glpi_consumableitemtypes                          | eq_ref | PRIMARY            | PRIMARY            | 4       | 10bugfixes.glpi_consumableitems.consumableitemtypes_id | 1    |                                              |
|    1 | SIMPLE      | glpi_entities                                     | eq_ref | PRIMARY            | PRIMARY            | 4       | 10bugfixes.glpi_consumableitems.entities_id            | 1    |                                              |
|    1 | SIMPLE      | glpi_consumables_3a1bfaeb0a6ab317f573339b5c25c067 | ref    | consumableitems_id | consumableitems_id | 4       | 10bugfixes.glpi_consumableitems.id                     | 354  |                                              |
+------+-------------+---------------------------------------------------+--------+--------------------+--------------------+---------+--------------------------------------------------------+------+----------------------------------------------+

note that this PR -> #16999
did not solve this problem (which must be different)

Q A
Bug fix? yes
New feature? no
BC breaks? no
Deprecations? no
Tests pass? yes
Fixed tickets !32718

@stonebuzz stonebuzz self-assigned this May 6, 2024
@stonebuzz stonebuzz added this to the 11.0.0 milestone May 6, 2024
@stonebuzz stonebuzz changed the title Optimize(Search): use LEFT JOIN filter on SELECT statement Optimize(Search): use LEFT JOIN filter on SELECT statement for Consumable May 6, 2024
@cconard96
Copy link
Contributor

cconard96 commented May 6, 2024

I haven't had time to test it, but could this be done with the undocumented computation parameter in the search options rather than a search engine workaround/hack?

This parameter is used at least in the Contract class.

@stonebuzz
Copy link
Contributor Author

good point, let me check if it works

@stonebuzz
Copy link
Contributor Author

@cconard96

You're right, using computation also works (it's much cleaner).

@stonebuzz
Copy link
Contributor Author

The latest commit prohibits the use of search options in meta search

Without this, the TU tries to use them (and gives an error) even though they are not available (natively) in the interface.

@trasher
Copy link
Contributor

trasher commented May 15, 2024

Could you please rebase this one? I cannot merge it right now, no idea why.

@stonebuzz
Copy link
Contributor Author

Could you please rebase this one? I cannot merge it right now, no idea why.

done =)

@trasher trasher merged commit 70572e8 into glpi-project:main May 15, 2024
8 checks passed
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.

None yet

5 participants