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

Slow performance of Products page builder element in the frontend when filtering by category #39577

Open
1 of 5 tasks
ioweb-gr opened this issue Jan 28, 2025 · 10 comments
Open
1 of 5 tasks
Labels
Area: Catalog Component: Catalog Issue: Confirmed Gate 3 Passed. Manual verification of the issue completed. Issue is confirmed Priority: P2 A defect with this priority could have functionality issues which are not to expectations. Reported on 2.4.7-p2 Indicates original Magento version for the Issue report. Reproduced on 2.4.x The issue has been reproduced on latest 2.4-develop branch Triage: Dev.Experience Issue related to Developer Experience and needs help with Triage to Confirm or Reject it

Comments

@ioweb-gr
Copy link
Contributor

Preconditions and environment

  • 2.4.7-p2
  • A very large catalog of configurable products (over 3 million skus and 50% at least configurable products)

Steps to reproduce

Add with the page builder a "Products" element to the homepage which filters products by category

Image

Go to the frontend and with a profiler check the queries generated

For example in my case this one was generated

SELECT DISTINCT `e`.`entity_id`
                  FROM `catalog_product_entity` AS `e`
                           INNER JOIN `catalog_product_index_price` AS `price_index`
                                      ON price_index.entity_id = e.entity_id AND price_index.customer_group_id = 0 AND
                                         price_index.website_id = '1'
                           INNER JOIN `catalog_product_website` AS `product_website`
                                      ON product_website.product_id = e.entity_id AND product_website.website_id = 1
                  WHERE (((IFNULL(`e`.`entity_id`, 0) IN (SELECT `catalog_category_product`.`product_id`
                                                          FROM `catalog_category_product`
                                                          WHERE (category_id IN ('794'))))))
[2025-01-28 16:35:57] 20 rows retrieved starting from 1 in 7 s 945 ms (execution: 7 s 787 ms, fetching: 158 ms)

This query takes about 9 seconds to run.

If rewritten in a different way like this it runs in 69ms

SELECT DISTINCT `e`.`entity_id`
                  FROM `catalog_product_entity` AS `e`
                           INNER JOIN `catalog_product_index_price` AS `price_index`
                                      ON price_index.entity_id = e.entity_id AND price_index.customer_group_id = 0 AND
                                         price_index.website_id = '1'
                           INNER JOIN `catalog_product_website` AS `product_website`
                                      ON product_website.product_id = e.entity_id AND product_website.website_id = 1
                  WHERE EXISTS (SELECT 1
                                FROM `catalog_category_product`
                                WHERE `catalog_category_product`.`product_id` = `e`.`entity_id`
                                  AND `catalog_category_product`.`category_id` IN ('794'))
[2025-01-28 16:36:20] 20 rows retrieved starting from 1 in 125 ms (execution: 69 ms, fetching: 56 ms)

So basically the way the category filter is used in the where condition is causing a huge delay.

With 2 instances of this type of widget the page takes over 20 seconds to load making it unusable.

Expected result

The products are loaded fast

Actual result

The page becomes unusable when using multiple widgets like this

Additional information

No response

Release note

No response

Triage and priority

  • Severity: S0 - Affects critical data or functionality and leaves users without workaround.
  • Severity: S1 - Affects critical data or functionality and forces users to employ a workaround.
  • Severity: S2 - Affects non-critical data or functionality and forces users to employ a workaround.
  • Severity: S3 - Affects non-critical data or functionality and does not force users to employ a workaround.
  • Severity: S4 - Affects aesthetics, professional look and feel, “quality” or “usability”.
Copy link

m2-assistant bot commented Jan 28, 2025

Hi @ioweb-gr. Thank you for your report.
To speed up processing of this issue, make sure that the issue is reproducible on the vanilla Magento instance following Steps to reproduce.


Join Magento Community Engineering Slack and ask your questions in #github channel.
⚠️ According to the Magento Contribution requirements, all issues must go through the Community Contributions Triage process. Community Contributions Triage is a public meeting.
🕙 You can find the schedule on the Magento Community Calendar page.
📞 The triage of issues happens in the queue order. If you want to speed up the delivery of your contribution, join the Community Contributions Triage session to discuss the appropriate ticket.

@engcom-Bravo engcom-Bravo added the Reported on 2.4.7-p2 Indicates original Magento version for the Issue report. label Jan 29, 2025
@github-project-automation github-project-automation bot moved this to Ready for Confirmation in Issue Confirmation and Triage Board Jan 29, 2025
@engcom-Bravo engcom-Bravo added the Triage: Dev.Experience Issue related to Developer Experience and needs help with Triage to Confirm or Reject it label Jan 29, 2025
@engcom-Hotel engcom-Hotel self-assigned this Jan 29, 2025
Copy link

m2-assistant bot commented Jan 29, 2025

Hi @engcom-Hotel. Thank you for working on this issue.
In order to make sure that issue has enough information and ready for development, please read and check the following instruction: 👇

  • 1. Verify that issue has all the required information. (Preconditions, Steps to reproduce, Expected result, Actual result).
  • 2. Verify that issue has a meaningful description and provides enough information to reproduce the issue.
  • 3. Add Area: XXXXX label to the ticket, indicating the functional areas it may be related to.
  • 4. Verify that the issue is reproducible on 2.4-develop branch
    Details- If the issue is reproducible on 2.4-develop branch, please, add the label Reproduced on 2.4.x.
    - If the issue is not reproducible, add your comment that issue is not reproducible and close the issue and stop verification process here!
  • 5. Add label Issue: Confirmed once verification is complete.
  • 6. Make sure that automatic system confirms that report has been added to the backlog.

@engcom-Hotel
Copy link
Contributor

Hello @ioweb-gr,

Thanks for the report and collaboration!

We have tried to reproduce the issue with the mentioned steps in the latest development branch i.e. 2.4-develop and it seems the issue has been reproducible for us. We have tried to reproduce the issue with almost 10 lakhs product and the query for us us as follows:

SELECT DISTINCT  `e`.`entity_id` FROM `catalog_product_entity` AS `e` INNER JOIN `catalog_product_index_price` AS `price_index` ON price_index.entity_id = e.entity_id AND price_index.customer_group_id = 0 AND price_index.website_id = '1' INNER JOIN `catalog_product_website` AS `product_website` ON product_website.product_id = e.entity_id AND product_website.website_id = 1 WHERE (((IFNULL(`e`.`entity_id`, 0) IN (SELECT `catalog_category_product`.`product_id` FROM
`catalog_category_product` WHERE (category_id IN ('3', '174', '175', '176', '177', '178', '179', '180', '181', '182', '183', '184', '185', '186', '187', '188', '189', '190', '191', '192', '193', '194', '195', '196', '197', '198', '199', '200', '201', '202', '203', '204', '205', '206', '207', '208', '209', '210', '211', '212', '213', '214', '215', '216', '217', '218', '219', '220', '221', '222', '223', '224', '225', '226', '227', '228', '229', '230', '231', '232', '233', '234', '235', '236', '237', '238', '239', '240', '241', '242', '243', '244', '245', '246', '247', '248', '249', '250', '251', '252', '253', '254', '255', '256', '257', '258', '259', '260', '261', '262', '263', '264', '265', '266', '267', '268', '269', '270', '271', '272', '273', '274', '275', '276', '277', '278',
'279', '280', '281', '282', '283', '284', '285', '286', '287', '288', '289', '290', '291', '292', '293', '294', '295', '296', '297', '298', '299', '300', '301', '302', '303', '304', '305', '306', '307', '308', '309', '310', '311', '312', '313', '314', '315', '316', '317', '318', '319', '320', '321', '322', '323', '324', '325', '326', '327', '328', '329', '330', '331', '332', '333', '334', '335', '336', '337', '338', '339', '340', '341', '342', '343', '4', '26', '27', '28', '29', '30', '31', '32', '33', '34', '35', '36', '37', '38', '39', '40', '41', '42', '43', '44', '45', '46', '47', '48', '49', '50', '51', '52', '53', '54', '55', '56', '57', '58', '59', '60', '61', '62', '63', '64', '65', '66', '67', '5', '11', '12', '13', '14', '15', '16', '17', '18', '19', '20', '21', '22', '23', '24', '25', '6', '10', '7', '8', '9', '68', '69', '70', '71', '72', '73', '74', '75', '76', '77', '78', '79', '80', '81', '82', '83', '84', '85', '86', '87', '88', '89', '111', '112', '113', '114', '115', '116', '117', '118', '119', '120', '121', '122', '123', '124', '125', '126', '127', '128', '129', '130', '131', '132', '133', '134', '135', '136', '137', '138', '139', '140', '141', '142', '143', '144', '145', '146', '147', '148', '149', '150', '151', '152', '153', '154', '155', '156', '157', '158', '159', '160', '161', '162', '163', '164', '165', '166', '167', '168', '169', '170', '171', '172', '173', '90', '101', '102', '103', '104', '105', '106', '107', '108', '109', '110', '91', '92', '93', '94', '95', '96', '100', '97', '98', '99')))) ));

The above query took 0.77 sec:
Image

Then we have tried with your suggested query as follows:

SELECT DISTINCT  `e`.`entity_id` FROM `catalog_product_entity` AS `e` INNER JOIN `catalog_product_index_price` AS `price_index` ON price_index.entity_id = e.entity_id AND price_index.customer_group_id = 0 AND price_index.website_id = '1' INNER JOIN `catalog_product_website` AS `product_website` ON product_website.product_id = e.entity_id AND product_website.website_id = 1 WHERE EXISTS (((SELECT 1 FROM `catalog_category_product` WHERE `catalog_category_product`.`product_id` = `e`.`entity_id` AND `catalog_category_product`.`category_id` IN ('3', '174', '175', '176', '177', '178', '179', '180', '181', '182', '183', '184', '185', '186', '187', '188', '189', '190', '191', '192', '193', '194', '195', '196', '197', '198', '199', '200', '201', '202', '203', '204', '205', '206', '207', '208', '209', '210', '211', '212', '213', '214', '215', '216', '217', '218', '219', '220', '221', '222', '223', '224', '225', '226', '227', '228', '229', '230', '231', '232', '233', '234', '235', '236', '237', '238', '239', '240', '241', '242', '243', '244', '245', '246', '247', '248', '249', '250', '251', '252', '253', '254', '255', '256', '257', '258', '259', '260', '261', '262', '263', '264', '265', '266', '267', '268', '269', '270', '271', '272', '273', '274', '275', '276', '277', '278', '279', '280', '281', '282', '283', '284', '285', '286', '287', '288', '289', '290', '291', '292', '293', '294', '295', '296', '297', '298', '299', '300', '301', '302', '303', '304', '305', '306', '307', '308', '309', '310', '311', '312', '313', '314', '315', '316', '317', '318', '319', '320', '321', '322', '323', '324', '325', '326', '327', '328', '329', '330', '331', '332', '333', '334', '335', '336', '337', '338', '339', '340', '341', '342', '343', '4', '26', '27', '28', '29', '30', '31', '32', '33', '34', '35', '36', '37', '38', '39', '40', '41', '42', '43', '44', '45', '46', '47', '48', '49', '50', '51', '52', '53', '54', '55', '56', '57', '58', '59', '60', '61', '62', '63', '64', '65', '66', '67', '5', '11', '12', '13', '14', '15', '16', '17', '18', '19', '20', '21', '22', '23', '24', '25', '6', '10', '7', '8', '9', '68', '69', '70', '71', '72', '73', '74', '75', '76', '77', '78', '79', '80', '81', '82', '83', '84', '85', '86', '87', '88', '89', '111', '112', '113', '114', '115', '116', '117', '118', '119', '120', '121', '122', '123', '124', '125', '126', '127', '128', '129', '130', '131', '132', '133', '134', '135', '136', '137', '138', '139', '140', '141', '142', '143', '144', '145', '146', '147', '148', '149', '150', '151', '152', '153', '154', '155', '156', '157', '158', '159', '160', '161', '162', '163', '164', '165', '166', '167', '168', '169', '170', '171', '172', '173', '90', '101', '102', '103', '104', '105', '106', '107', '108', '109', '110', '91', '92', '93', '94', '95', '96', '100', '97', '98', '99'))));

which took 0.47 sec to complete:
Image

It clearly shows that there is room for query optimization. Hence confirming the issue.

Thanks

@engcom-Hotel engcom-Hotel added Component: Catalog Issue: Confirmed Gate 3 Passed. Manual verification of the issue completed. Issue is confirmed Reproduced on 2.4.x The issue has been reproduced on latest 2.4-develop branch Priority: P2 A defect with this priority could have functionality issues which are not to expectations. Area: Catalog and removed Issue: ready for confirmation labels Jan 29, 2025
@github-jira-sync-bot
Copy link

✅ Jira issue https://jira.corp.adobe.com/browse/AC-13843 is successfully created for this GitHub issue.

Copy link

m2-assistant bot commented Jan 29, 2025

✅ Confirmed by @engcom-Hotel. Thank you for verifying the issue.
Issue Available: @engcom-Hotel, You will be automatically unassigned. Contributors/Maintainers can claim this issue to continue. To reclaim and continue work, reassign the ticket to yourself.

@ioweb-gr
Copy link
Contributor Author

The query difference compared to what I see is drastic. In your case it's half the time but in my case it was multiple times slower @engcom-Hotel

Could you share the DB configuration you used to see if there's some optimization factor producing this difference?

@ioweb-gr
Copy link
Contributor Author

And actually using your own query it took for me 100ms

SELECT DISTINCT `e`.`entity_id`
                  FROM `catalog_product_entity` AS `e`
                           INNER JOIN `catalog_product_index_price` AS `price_index`
                                      ON price_index.entity_id = e.entity_id AND price_index.customer_group_id = 0 AND
                                         price_index.website_id = '1'
                           INNER JOIN `catalog_product_website` AS `product_website`
                                      ON product_website.product_id = e.entity_id AND product_website.website_id = 1
                  WHERE (((IFNULL(`e`.`entity_id`, 0) IN (SELECT `catalog_category_product`.`product_id`
                                                          FROM `catalog_category_product`
                                                          WHERE (category_id IN
                                                                 ('3', '174', '175', '176', '177', '178', '179', '180', '181', '182',
                                                                  '183', '184', '185', '186', '187', '188', '189', '190', '191', '192',
                                                                  '193', '194', '195', '196', '197', '198', '199', '200', '201', '202',
                                                                  '203', '204', '205', '206', '207', '208', '209', '210', '211', '212',
                                                                  '213', '214', '215', '216', '217', '218', '219', '220', '221', '222',
                                                                  '223', '224', '225', '226', '227', '228', '229', '230', '231', '232',
                                                                  '233', '234', '235', '236', '237', '238', '239', '240', '241', '242',
                                                                  '243', '244', '245', '246', '247', '248', '249', '250', '251', '252',
                                                                  '253', '254', '255', '256', '257', '258', '259', '260', '261', '262',
                                                                  '263', '264', '265', '266', '267', '268', '269', '270', '271', '272',
                                                                  '273', '274', '275', '276', '277', '278',
                                                                  '279', '280', '281', '282', '283', '284', '285', '286', '287', '288',
                                                                  '289', '290', '291', '292', '293', '294', '295', '296', '297', '298',
                                                                  '299', '300', '301', '302', '303', '304', '305', '306', '307', '308',
                                                                  '309', '310', '311', '312', '313', '314', '315', '316', '317', '318',
                                                                  '319', '320', '321', '322', '323', '324', '325', '326', '327', '328',
                                                                  '329', '330', '331', '332', '333', '334', '335', '336', '337', '338',
                                                                  '339', '340', '341', '342', '343', '4', '26', '27', '28', '29', '30',
                                                                  '31', '32', '33', '34', '35', '36', '37', '38', '39', '40', '41', '42',
                                                                  '43', '44', '45', '46', '47', '48', '49', '50', '51', '52', '53', '54',
                                                                  '55', '56', '57', '58', '59', '60', '61', '62', '63', '64', '65', '66',
                                                                  '67', '5', '11', '12', '13', '14', '15', '16', '17', '18', '19', '20',
                                                                  '21', '22', '23', '24', '25', '6', '10', '7', '8', '9', '68', '69',
                                                                  '70', '71', '72', '73', '74', '75', '76', '77', '78', '79', '80', '81',
                                                                  '82', '83', '84', '85', '86', '87', '88', '89', '111', '112', '113',
                                                                  '114', '115', '116', '117', '118', '119', '120', '121', '122', '123',
                                                                  '124', '125', '126', '127', '128', '129', '130', '131', '132', '133',
                                                                  '134', '135', '136', '137', '138', '139', '140', '141', '142', '143',
                                                                  '144', '145', '146', '147', '148', '149', '150', '151', '152', '153',
                                                                  '154', '155', '156', '157', '158', '159', '160', '161', '162', '163',
                                                                  '164', '165', '166', '167', '168', '169', '170', '171', '172', '173',
                                                                  '90', '101', '102', '103', '104', '105', '106', '107', '108', '109',
                                                                  '110', '91', '92', '93', '94', '95', '96', '100', '97', '98',
                                                                  '99'))))))
[2025-01-29 15:15:24] 500 rows retrieved starting from 1 in 676 ms (execution: 101 ms, fetching: 575 ms)

@ioweb-gr
Copy link
Contributor Author

ioweb-gr commented Jan 29, 2025

I did some playing around and it seems that the more category ids we put in the IN clause, the faster the query becomes even if each category has tons of products. Most likely the optimizer is choosing a different path

For example

SELECT DISTINCT `e`.`entity_id`
FROM `catalog_product_entity` AS `e`
         INNER JOIN `catalog_product_index_price` AS `price_index`
                    ON price_index.entity_id = e.entity_id AND price_index.customer_group_id = 0 AND
                       price_index.website_id = '1'
         INNER JOIN `catalog_product_website` AS `product_website`
                    ON product_website.product_id = e.entity_id AND product_website.website_id = 1
WHERE (((IFNULL(`e`.`entity_id`, 0) IN (SELECT `catalog_category_product`.`product_id`
                                        FROM `catalog_category_product`
                                        WHERE (category_id IN (3,174,175,176,177))))));

This one took 100ms for me

Whilst if I remove any of the category_ids from those , it takes 7 seconds.

@engcom-Hotel would you mind giving it another shot by selecting only 2-3 categories in the PRODUCTS widget for the page builder?

@engcom-Hotel
Copy link
Contributor

Hello @ioweb-gr,

I have tried it with 3 category IDs and the query took 0.42 sec:

Image

And then tried with 1 category ID and this time query took 1.94 sec:

Image

@ioweb-gr
Copy link
Contributor Author

Thank you for confirming performance degradation @engcom-Hotel

Let me tell you what I found from my investigation.

It seems the amount of products in the categories plays a role but the inverse of what seems logical.

Assuming the query only has one category I get different results if that category has less or more products. In particular, the more products it has, the faster the query becomes.

I'm experimenting with filtering just on category_id = 794 which I can control the count of products.
As I increase the amount of products in 794, the speed improves.

With 10 products it takes 15 seconds
With 1000 products it takes 4.3 seconds
With 3000 products it takes 3.8 seconds.
With 6000 products it takes 1.2 seconds

It's definitely the IFNULL condition that's causing this performance degradation but I can't understand why the number of products plays a role.

In your case since you had added dozens of categories, the query became fast, even if it was 50% slower than the sample I gave.
But in my case where the category had 10 products, the query was magnitudes slower

I tested in both MariaDB 10.6 and MySQL 8 to see if there's a difference in the optimizers.

The execution plans appear identical though so it's really vexing.

I also have one more observation that I noticed and it's that the query created by the PageBuilder Products element is ignoring the products_count in the widget.

If you check the QUERY it has no "LIMIT" clause.

In my widget I always limit the products to a sane number like 2 or 5 or 10

But the query is running for all. This could also play a part but a very small one.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
Area: Catalog Component: Catalog Issue: Confirmed Gate 3 Passed. Manual verification of the issue completed. Issue is confirmed Priority: P2 A defect with this priority could have functionality issues which are not to expectations. Reported on 2.4.7-p2 Indicates original Magento version for the Issue report. Reproduced on 2.4.x The issue has been reproduced on latest 2.4-develop branch Triage: Dev.Experience Issue related to Developer Experience and needs help with Triage to Confirm or Reject it
Projects
None yet
Development

No branches or pull requests

4 participants