Optimize the query to count products using the attributes lookup table.

The query to count products using the attributes lookup table for the
filter by attribute widget was adding an "AND term_ids in (...)"-type
subquery for each attribute participating in the filtering. Now at most
two such subqueries are generated, one for attributes configured for
OR type filtering and another one for the ones configured as AND; this
speeds up the query significantly when many attributes are used
simultaneously for the filtering.
This commit is contained in:
Nestor Soriano 2021-07-12 10:32:14 +02:00
parent 4b4f9a2b5d
commit aa967cab4f
No known key found for this signature in database
GPG Key ID: 08110F3518C12CAD
1 changed files with 42 additions and 33 deletions

View File

@ -213,41 +213,50 @@ class Filterer {
$attributes_to_filter_by = \WC_Query::get_layered_nav_chosen_attributes(); $attributes_to_filter_by = \WC_Query::get_layered_nav_chosen_attributes();
if ( ! empty( $attributes_to_filter_by ) ) { if ( ! empty( $attributes_to_filter_by ) ) {
$all_terms_to_filter_by = array(); $and_term_ids = array();
$or_term_ids = array();
foreach ( $attributes_to_filter_by as $taxonomy => $data ) { foreach ( $attributes_to_filter_by as $taxonomy => $data ) {
$all_terms = get_terms( $taxonomy, array( 'hide_empty' => false ) ); $all_terms = get_terms( $taxonomy, array( 'hide_empty' => false ) );
$term_ids_by_slug = wp_list_pluck( $all_terms, 'term_id', 'slug' ); $term_ids_by_slug = wp_list_pluck( $all_terms, 'term_id', 'slug' );
$term_ids_to_filter_by = array_values( array_intersect_key( $term_ids_by_slug, array_flip( $data['terms'] ) ) ); $term_ids_to_filter_by = array_values( array_intersect_key( $term_ids_by_slug, array_flip( $data['terms'] ) ) );
$all_terms_to_filter_by = array_merge( $all_terms_to_filter_by, $term_ids_to_filter_by ); if ( 'and' === $data['query_type'] ) {
$term_ids_to_filter_by_list = '(' . join( ',', $term_ids_to_filter_by ) . ')'; $and_term_ids = array_merge( $and_term_ids, $term_ids_to_filter_by );
} else {
$or_term_ids = array_merge( $or_term_ids, $term_ids_to_filter_by );
}
}
$count = count( $term_ids_to_filter_by ); if ( ! empty( $and_term_ids ) ) {
if ( 0 !== $count ) { $terms_count = count( $and_term_ids );
$query['where'] .= ' AND product_or_parent_id IN ('; $term_ids_list = '(' . join( ',', $and_term_ids ) . ')';
if ( 'and' === $attributes_to_filter_by[ $taxonomy ]['query_type'] ) {
$query['where'] .= " $query['where'] .= "
AND product_or_parent_id IN (
SELECT product_or_parent_id SELECT product_or_parent_id
FROM {$this->lookup_table_name} lt FROM {$this->lookup_table_name} lt
WHERE is_variation_attribute=0 WHERE is_variation_attribute=0
{$in_stock_clause} {$in_stock_clause}
AND term_id in {$term_ids_to_filter_by_list} AND term_id in {$term_ids_list}
GROUP BY product_id GROUP BY product_id
HAVING COUNT(product_id)={$count} HAVING COUNT(product_id)={$terms_count}
UNION UNION
SELECT product_or_parent_id SELECT product_or_parent_id
FROM {$this->lookup_table_name} lt FROM {$this->lookup_table_name} lt
WHERE is_variation_attribute=1 WHERE is_variation_attribute=1
{$in_stock_clause} {$in_stock_clause}
AND term_id in {$term_ids_to_filter_by_list} AND term_id in {$term_ids_list}
)"; )";
} else { }
if ( ! empty( $or_term_ids ) ) {
$term_ids_list = '(' . join( ',', $or_term_ids ) . ')';
$query['where'] .= " $query['where'] .= "
AND product_or_parent_id IN (
SELECT product_or_parent_id FROM {$this->lookup_table_name} SELECT product_or_parent_id FROM {$this->lookup_table_name}
WHERE term_id in {$term_ids_to_filter_by_list} WHERE term_id in {$term_ids_list}
{$in_stock_clause} {$in_stock_clause}
)"; )";
}
}
} }
} else { } else {
$query['where'] .= $in_stock_clause; $query['where'] .= $in_stock_clause;