Open
Description
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
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”.
Metadata
Metadata
Assignees
Labels
Gate 3 Passed. Manual verification of the issue completed. Issue is confirmedA defect with this priority could have functionality issues which are not to expectations.Indicates original Magento version for the Issue report.The issue has been reproduced on latest 2.4-develop branchIssue related to Developer Experience and needs help with Triage to Confirm or Reject it