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): Handle LEFT JOIN which concern counting operatio lastly #16997

Conversation

stonebuzz
Copy link
Contributor

On one customer's instance, we were confronted with major problems of slowness on the software list.

The first 50 softwares took almost 13 seconds to load.

Here is the list of columns displayed on the customer's site

image

By digging around, I've come to understand that if the column that counts the number of installations (glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9) is followed by any other LEFT JOIN glpi_states_0a35c270152be19b5c8a485502badcd7, the SQL query takes an enormous amount of time (13.877 sec).

SELECT DISTINCT `glpi_softwares`.`id` AS id,
         'supportcloud' AS currentuser, `glpi_softwares`.`entities_id`, `glpi_softwares`.`is_recursive`, `glpi_softwares`.`name` AS `ITEM_Software_1`, 
         `glpi_softwares`.`id` AS `ITEM_Software_1_id`, `glpi_entities`.`completename` AS `ITEM_Software_80`, `glpi_manufacturers`.`name` AS `ITEM_Software_23`, 
         GROUP_CONCAT(DISTINCT CONCAT(IFNULL(`glpi_softwareversions`.`name`, '__NULL__'), '$#$',`glpi_softwareversions`.`id`)
ORDER BY  `glpi_softwareversions`.`id` SEPARATOR '$$##$$') AS `ITEM_Software_5`, GROUP_CONCAT(DISTINCT CONCAT(IFNULL(`glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7`.`name`, '__NULL__'), '$#$',`glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7`.`id`)
ORDER BY  `glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7`.`id` SEPARATOR '$$##$$') AS `ITEM_Software_4`, FLOOR(SUM(`glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`number`) * COUNT(DISTINCT `glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`id`) / COUNT(`glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`id`)) AS `ITEM_Software_163`, MIN(`glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`number`) AS `ITEM_Software_163_min`, COUNT(DISTINCT `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`.`id`) AS `ITEM_Software_72`, GROUP_CONCAT(DISTINCT CONCAT(IFNULL(`glpi_states_0a35c270152be19b5c8a485502badcd7`.`completename`, '__NULL__'), '$#$',`glpi_states_0a35c270152be19b5c8a485502badcd7`.`id`)
ORDER BY  `glpi_states_0a35c270152be19b5c8a485502badcd7`.`id` SEPARATOR '$$##$$') AS `ITEM_Software_31`
FROM `glpi_softwares`
LEFT JOIN `glpi_entities`
    ON (`glpi_softwares`.`entities_id` = `glpi_entities`.`id` )
LEFT JOIN `glpi_manufacturers`
    ON (`glpi_softwares`.`manufacturers_id` = `glpi_manufacturers`.`id` )
LEFT JOIN `glpi_softwareversions`
    ON (`glpi_softwares`.`id` = `glpi_softwareversions`.`softwares_id` )
LEFT JOIN `glpi_operatingsystems` AS `glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7`
    ON (`glpi_softwareversions`.`operatingsystems_id` = `glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7`.`id` )
LEFT JOIN `glpi_softwarelicenses` AS `glpi_softwarelicenses_6427cab6934982da77f819e079502198`
    ON (`glpi_softwares`.`id` = `glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`softwares_id`
        AND `glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`is_template` = '0'
        AND ((`glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`expire` IS NULL)
        OR (`glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`expire` > NOW())) )
LEFT JOIN `glpi_items_softwareversions` AS `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`
    ON (`glpi_softwareversions`.`id` = `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`.`softwareversions_id`
        AND `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`.`is_deleted_item` = '0'
        AND `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`.`is_deleted` = '0'
        AND `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`.`is_template_item` = '0' )
LEFT JOIN `glpi_states` AS `glpi_states_0a35c270152be19b5c8a485502badcd7`
    ON (`glpi_softwareversions`.`states_id` = `glpi_states_0a35c270152be19b5c8a485502badcd7`.`id` )
WHERE `glpi_softwares`.`is_deleted` = 0
        AND `glpi_softwares`.`is_template` = 0
GROUP BY  `glpi_softwares`.`id`
ORDER BY  `id` LIMIT 0, 50

Conversely, if the column counting the number of installations is the last, the loading time is very reasonable (0.008 sec).

SELECT DISTINCT `glpi_softwares`.`id` AS id,
         'supportcloud' AS currentuser, `glpi_softwares`.`entities_id`, `glpi_softwares`.`is_recursive`, `glpi_softwares`.`name` AS `ITEM_Software_1`, 
         `glpi_softwares`.`id` AS `ITEM_Software_1_id`, `glpi_entities`.`completename` AS `ITEM_Software_80`, `glpi_manufacturers`.`name` AS `ITEM_Software_23`, 
         GROUP_CONCAT(DISTINCT CONCAT(IFNULL(`glpi_softwareversions`.`name`, '__NULL__'), '$#$',`glpi_softwareversions`.`id`)
ORDER BY  `glpi_softwareversions`.`id` SEPARATOR '$$##$$') AS `ITEM_Software_5`, GROUP_CONCAT(DISTINCT CONCAT(IFNULL(`glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7`.`name`, '__NULL__'), '$#$',`glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7`.`id`)
ORDER BY  `glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7`.`id` SEPARATOR '$$##$$') AS `ITEM_Software_4`, FLOOR(SUM(`glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`number`) * COUNT(DISTINCT `glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`id`) / COUNT(`glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`id`)) AS `ITEM_Software_163`, MIN(`glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`number`) AS `ITEM_Software_163_min`, COUNT(DISTINCT `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`.`id`) AS `ITEM_Software_72`, GROUP_CONCAT(DISTINCT CONCAT(IFNULL(`glpi_states_0a35c270152be19b5c8a485502badcd7`.`completename`, '__NULL__'), '$#$',`glpi_states_0a35c270152be19b5c8a485502badcd7`.`id`)
ORDER BY  `glpi_states_0a35c270152be19b5c8a485502badcd7`.`id` SEPARATOR '$$##$$') AS `ITEM_Software_31`
FROM `glpi_softwares`
LEFT JOIN `glpi_entities`
    ON (`glpi_softwares`.`entities_id` = `glpi_entities`.`id` )
LEFT JOIN `glpi_manufacturers`
    ON (`glpi_softwares`.`manufacturers_id` = `glpi_manufacturers`.`id` )
LEFT JOIN `glpi_softwareversions`
    ON (`glpi_softwares`.`id` = `glpi_softwareversions`.`softwares_id` )
LEFT JOIN `glpi_operatingsystems` AS `glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7`
    ON (`glpi_softwareversions`.`operatingsystems_id` = `glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7`.`id` )
LEFT JOIN `glpi_softwarelicenses` AS `glpi_softwarelicenses_6427cab6934982da77f819e079502198`
    ON (`glpi_softwares`.`id` = `glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`softwares_id`
        AND `glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`is_template` = '0'
        AND ((`glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`expire` IS NULL)
        OR (`glpi_softwarelicenses_6427cab6934982da77f819e079502198`.`expire` > NOW())) )
LEFT JOIN `glpi_states` AS `glpi_states_0a35c270152be19b5c8a485502badcd7`
    ON (`glpi_softwareversions`.`states_id` = `glpi_states_0a35c270152be19b5c8a485502badcd7`.`id` )
LEFT JOIN `glpi_items_softwareversions` AS `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`
    ON (`glpi_softwareversions`.`id` = `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`.`softwareversions_id`
        AND `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`.`is_deleted_item` = '0'
        AND `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`.`is_deleted` = '0'
        AND `glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9`.`is_template_item` = '0' )
WHERE `glpi_softwares`.`is_deleted` = 0
        AND `glpi_softwares`.`is_template` = 0
GROUP BY  `glpi_softwares`.`id`
ORDER BY  `id` LIMIT 0, 50

I have therefore deduced that there is a performance problem with the order of the LEFT JOIN when GLPI creates the SQL query.

An EXPLAIN of the SQL query seems to confirm this

SQL query with "bad" LEFT JOIN order (last LEFT JOIN on glpi_states use Using join buffer instead of where (see Extra column) maybe because key, key_len and ref are null)

+------+-------------+--------------------------------------------------------------+-------------+-----------------------------------------------------------------+----------------------------+---------+------------------------------------------------+--------+---------------------------------------------------------------------------------------+
| id   | select_type | table                                                        | type        | possible_keys                                                   | key                        | key_len | ref                                            | rows   | Extra                                                                                 |
+------+-------------+--------------------------------------------------------------+-------------+-----------------------------------------------------------------+----------------------------+---------+------------------------------------------------+--------+---------------------------------------------------------------------------------------+
|    1 | SIMPLE      | glpi_softwares                                               | index_merge | is_template,is_deleted                                          | is_template,is_deleted     | 1,1     | NULL                                           | 122424 | Using intersect(is_template,is_deleted); Using where; Using temporary; Using filesort |
|    1 | SIMPLE      | glpi_entities                                                | eq_ref      | PRIMARY                                                         | PRIMARY                    | 4       | glpi.glpi_softwares.entities_id                | 1      |                                                                                       |
|    1 | SIMPLE      | glpi_manufacturers                                           | eq_ref      | PRIMARY                                                         | PRIMARY                    | 4       | glpi.glpi_softwares.manufacturers_id           | 1      |                                                                                       |
|    1 | SIMPLE      | glpi_softwareversions                                        | ref         | softwares_id                                                    | softwares_id               | 4       | glpi.glpi_softwares.id                         | 1      |                                                                                       |
|    1 | SIMPLE      | glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7       | eq_ref      | PRIMARY                                                         | PRIMARY                    | 4       | glpi.glpi_softwareversions.operatingsystems_id | 1      | Using where                                                                           |
|    1 | SIMPLE      | glpi_softwarelicenses_6427cab6934982da77f819e079502198       | ref         | is_template,expire,softwares_id_expire_number                   | softwares_id_expire_number | 4       | glpi.glpi_softwares.id                         | 1      | Using where                                                                           |
|    1 | SIMPLE      | glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9 | ref         | softwareversions_id,is_deleted,is_deleted_item,is_template_item | softwareversions_id        | 4       | glpi.glpi_softwareversions.id                  | 1      | Using where                                                                           |
|    1 | SIMPLE      | glpi_states_0a35c270152be19b5c8a485502badcd7                 | ALL         | PRIMARY                                                         | NULL                       | NULL    | NULL                                           | 15     | Using where; Using join buffer (flat, BNL join)                                       |
+------+-------------+--------------------------------------------------------------+-------------+-----------------------------------------------------------------+----------------------------+---------+------------------------------------------------+--------+---------------------------------------------------------------------------------------+

SQL query with "good" LEFT JOIN order (only where is used see Extra column)

+------+-------------+--------------------------------------------------------------+--------+-----------------------------------------------------------------+----------------------------+---------+------------------------------------------------+------+-------------+
| id   | select_type | table                                                        | type   | possible_keys                                                   | key                        | key_len | ref                                            | rows | Extra       |
+------+-------------+--------------------------------------------------------------+--------+-----------------------------------------------------------------+----------------------------+---------+------------------------------------------------+------+-------------+
|    1 | SIMPLE      | glpi_softwares                                               | index  | is_template,is_deleted                                          | PRIMARY                    | 4       | NULL                                           | 1600 | Using where |
|    1 | SIMPLE      | glpi_entities                                                | eq_ref | PRIMARY                                                         | PRIMARY                    | 4       | glpi.glpi_softwares.entities_id                | 1    |             |
|    1 | SIMPLE      | glpi_manufacturers                                           | eq_ref | PRIMARY                                                         | PRIMARY                    | 4       | glpi.glpi_softwares.manufacturers_id           | 1    |             |
|    1 | SIMPLE      | glpi_softwareversions                                        | ref    | softwares_id                                                    | softwares_id               | 4       | glpi.glpi_softwares.id                         | 1    |             |
|    1 | SIMPLE      | glpi_operatingsystems_0a35c270152be19b5c8a485502badcd7       | eq_ref | PRIMARY                                                         | PRIMARY                    | 4       | glpi.glpi_softwareversions.operatingsystems_id | 1    | Using where |
|    1 | SIMPLE      | glpi_softwarelicenses_6427cab6934982da77f819e079502198       | ref    | is_template,expire,softwares_id_expire_number                   | softwares_id_expire_number | 4       | glpi.glpi_softwares.id                         | 1    | Using where |
|    1 | SIMPLE      | glpi_states_0a35c270152be19b5c8a485502badcd7                 | eq_ref | PRIMARY                                                         | PRIMARY                    | 4       | glpi.glpi_softwareversions.states_id           | 1    | Using where |
|    1 | SIMPLE      | glpi_items_softwareversions_37010ce8f4633da91ded3e0a4c256dc9 | ref    | softwareversions_id,is_deleted,is_deleted_item,is_template_item | softwareversions_id        | 4       | glpi.glpi_softwareversions.id                  | 1    | Using where |
+------+-------------+--------------------------------------------------------------+--------+-----------------------------------------------------------------+----------------------------+---------+------------------------------------------------+------+-------------+

The idea of this PR is therefore to reorganise the searchoption order according to datatype

If equal to count put at the end, otherwise at the beginning

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

@stonebuzz
Copy link
Contributor Author

let's wait for the unit tests before giving our verdict

@stonebuzz
Copy link
Contributor Author

after a quick test on the list of tickets with the number of follow-ups column, followed by any column, I don't see the problem

so I deduce that this only happens when the intermediate table is very large (1 million rows for my client)

@orthagh
Copy link
Contributor

orthagh commented Apr 24, 2024

This kind of change is dangerous on 10.0/bf.
Please target main and provide a backport on support.

@stonebuzz
Copy link
Contributor Author

I close in favour of #16999

@stonebuzz stonebuzz closed this Apr 24, 2024
@stonebuzz stonebuzz mentioned this pull request Apr 25, 2024
2 tasks
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.

2 participants