Skip to content

Commit

Permalink
[-] FO : Fix performances issue with SpecificPrice (PSCSX-6942)
Browse files Browse the repository at this point in the history
  • Loading branch information
jocel1 committed Oct 21, 2015
1 parent dcb70b6 commit c140d7a
Show file tree
Hide file tree
Showing 5 changed files with 186 additions and 76 deletions.
3 changes: 1 addition & 2 deletions classes/Category.php
Expand Up @@ -771,8 +771,7 @@ public function getProducts($id_lang, $p, $n, $order_by = null, $order_way = nul
AND cp.`id_category` = '.(int)$this->id
.($active ? ' AND product_shop.`active` = 1' : '')
.($front ? ' AND product_shop.`visibility` IN ("both", "catalog")' : '')
.($id_supplier ? ' AND p.id_supplier = '.(int)$id_supplier : '')
.' GROUP BY cp.id_product';
.($id_supplier ? ' AND p.id_supplier = '.(int)$id_supplier : '');

if ($random === true) {
$sql .= ' ORDER BY RAND() LIMIT '.(int)$random_number_products;
Expand Down
17 changes: 8 additions & 9 deletions classes/Product.php
Expand Up @@ -2269,7 +2269,7 @@ public static function getNewProducts($id_lang, $page_number = 0, $nb_products =
$order_way = 'DESC';
}
if ($order_by == 'id_product' || $order_by == 'price' || $order_by == 'date_add' || $order_by == 'date_upd') {
$order_by_prefix = 'p';
$order_by_prefix = 'product_shop';
} elseif ($order_by == 'name') {
$order_by_prefix = 'pl';
}
Expand Down Expand Up @@ -2325,11 +2325,11 @@ public static function getNewProducts($id_lang, $page_number = 0, $nb_products =
}
$sql->where('product_shop.`date_add` > "'.date('Y-m-d', strtotime('-'.(Configuration::get('PS_NB_DAYS_NEW_PRODUCT') ? (int)Configuration::get('PS_NB_DAYS_NEW_PRODUCT') : 20).' DAY')).'"');
if (Group::isFeatureActive()) {
$sql->join('JOIN '._DB_PREFIX_.'category_product cp ON (cp.id_product = p.id_product)');
$sql->join('JOIN '._DB_PREFIX_.'category_group cg ON (cg.id_category = cp.id_category)');
$sql->where('cg.`id_group` '.(count($groups) ? 'IN ('.implode(',', $groups).')' : '= 1'));
$groups = FrontController::getCurrentCustomerGroups();
$sql->where('EXISTS(SELECT 1 FROM `'._DB_PREFIX_.'category_product` cp
JOIN `'._DB_PREFIX_.'category_group` cg ON (cp.id_category = cg.id_category AND cg.`id_group` '.(count($groups) ? 'IN ('.implode(',', $groups).')' : '= 1').')
WHERE cp.`id_product` = p.`id_product`)');
}
$sql->groupBy('product_shop.id_product');

$sql->orderBy((isset($order_by_prefix) ? pSQL($order_by_prefix).'.' : '').'`'.pSQL($order_by).'` '.pSQL($order_way));
$sql->limit($nb_products, $page_number * $nb_products);
Expand Down Expand Up @@ -2398,7 +2398,7 @@ public static function getRandomSpecial($id_lang, $beginning = false, $ending =
$front = false;
}

$current_date = date('Y-m-d H:i:s');
$current_date = date('Y-m-d H:i:00');
$product_reductions = Product::_getProductIdByDate((!$beginning ? $current_date : $beginning), (!$ending ? $current_date : $ending), $context, true);

if ($product_reductions) {
Expand Down Expand Up @@ -2502,14 +2502,14 @@ public static function getPricesDrop($id_lang, $page_number = 0, $nb_products =
$order_way = 'DESC';
}
if ($order_by == 'id_product' || $order_by == 'price' || $order_by == 'date_add' || $order_by == 'date_upd') {
$order_by_prefix = 'p';
$order_by_prefix = 'product_shop';
} elseif ($order_by == 'name') {
$order_by_prefix = 'pl';
}
if (!Validate::isOrderBy($order_by) || !Validate::isOrderWay($order_way)) {
die(Tools::displayError());
}
$current_date = date('Y-m-d H:i:s');
$current_date = date('Y-m-d H:i:00');
$ids_product = Product::_getProductIdByDate((!$beginning ? $current_date : $beginning), (!$ending ? $current_date : $ending), $context);

$tab_id_product = array();
Expand Down Expand Up @@ -2582,7 +2582,6 @@ public static function getPricesDrop($id_lang, $page_number = 0, $nb_products =
'.($front ? ' AND p.`visibility` IN ("both", "catalog")' : '').'
'.((!$beginning && !$ending) ? ' AND p.`id_product` IN ('.((is_array($tab_id_product) && count($tab_id_product)) ? implode(', ', $tab_id_product) : 0).')' : '').'
'.$sql_groups.'
GROUP BY p.id_product
ORDER BY '.(isset($order_by_prefix) ? pSQL($order_by_prefix).'.' : '').pSQL($order_by).' '.pSQL($order_way).'
LIMIT '.(int)($page_number * $nb_products).', '.(int)$nb_products;

Expand Down
223 changes: 160 additions & 63 deletions classes/SpecificPrice.php
Expand Up @@ -89,7 +89,9 @@ class SpecificPriceCore extends ObjectModel


protected static $_specificPriceCache = array();
protected static $_filterOutCache = array();
protected static $_cache_priorities = array();
protected static $_no_specific_values = array();

public function add($autodate = true, $nullValues = false)
{
Expand Down Expand Up @@ -198,6 +200,132 @@ public static function getPriority($id_product)
return preg_split('/;/', $priority);
}

/**
* Remove or add a field value to a query if values are present in the database (cache friendly)
*
* @param string $field_name
* @param int $field_value
* @param int $threshold
* @return string
* @throws PrestaShopDatabaseException
*/
private static function filterOutField($field_name, $field_value, $threshold = 1000)

This comment has been minimized.

Copy link
@yelmontaser

yelmontaser Nov 5, 2015

Why we cannot override your methods?

{
$query_extra = 'AND `'.$field_name.'` = 0 ';
if ($field_value == 0 || array_key_exists($field_name, self::$_no_specific_values)) {
return $query_extra;
}
$key_cache = __FUNCTION__.'-'.$field_name.'-'.$threshold;
$specific_list = array();
if (!array_key_exists($key_cache, SpecificPrice::$_filterOutCache)) {
$query_count = 'SELECT COUNT(DISTINCT `'.$field_name.'`) FROM `'._DB_PREFIX_.'specific_price` WHERE `'.$field_name.'` != 0';
$specific_count = Db::getInstance(_PS_USE_SQL_SLAVE_)->getValue($query_count);
if ($specific_count == 0) {
self::$_no_specific_values[$field_name] = true;

return $query_extra;
}
if ($specific_count < $threshold) {

This comment has been minimized.

Copy link
@yelmontaser

yelmontaser Nov 5, 2015

The specific prices do not work if you have more than 1000. you have a problem on this line.

This comment has been minimized.

Copy link
@jocel1

jocel1 Nov 6, 2015

Author Contributor

Hi @yelmontaser,

Good catch, this should be fixed in #4412

Thanks!

$query = 'SELECT DISTINCT `'.$field_name.'` FROM `'._DB_PREFIX_.'specific_price` WHERE `'.$field_name.'` != 0';
$tmp_specific_list = Db::getInstance(_PS_USE_SQL_SLAVE_)->executeS($query);
foreach ($tmp_specific_list as $key => $value) {
$specific_list[] = $value[$field_name];
}
}
SpecificPrice::$_filterOutCache[$key_cache] = $specific_list;
} else {
$specific_list = SpecificPrice::$_filterOutCache[$key_cache];
}

if (in_array($field_value, $specific_list)) {
$query_extra = 'AND `'.$field_name.'` '.self::formatIntInQuery(0, $field_value).' ';
}

return $query_extra;
}

/**
* Remove or add useless fields value depending on the values in the database (cache friendly)
*
* @param int|null $id_product
* @param int|null $id_product_attribute
* @param int|null $id_cart
* @param string|null $beginning
* @param string|null $ending
* @return string
*/
private static function computeExtraConditions($id_product, $id_product_attribute, $id_customer, $id_cart, $beginning = null, $ending = null)

This comment has been minimized.

Copy link
@yelmontaser

yelmontaser Nov 5, 2015

idem.

{
$first_date = date('Y-m-d 00:00:00');
$last_date = date('Y-m-d 23:59:59');
$now = date('Y-m-d H:i:00');
if ($beginning === null) {
$beginning = $now;
}
if ($ending === null) {
$ending = $now;
}
$id_customer = (int)$id_customer;

$query_extra = '';

if ($id_product !== null) {
$query_extra .= self::filterOutField('id_product', $id_product);
}

if ($id_customer !== null) {
$query_extra .= self::filterOutField('id_customer', $id_customer);
}

if ($id_product_attribute !== null) {
$query_extra .= self::filterOutField('id_product_attribute', $id_product_attribute);
}

if ($id_cart !== null) {
$query_extra .= self::filterOutField('id_cart', $id_cart);
}

if ($ending == $now && $beginning == $now) {
$key = __FUNCTION__.'-'.$first_date.'-'.$last_date;
if (!array_key_exists($key, SpecificPrice::$_filterOutCache)) {
$query_from_count = 'SELECT 1 FROM `'._DB_PREFIX_.'specific_price` WHERE `from` BETWEEN \''.$first_date.'\' AND \''.$last_date.'\'';
$from_specific_count = Db::getInstance(_PS_USE_SQL_SLAVE_)->getValue($query_from_count);

$query_to_count = 'SELECT 1 FROM `'._DB_PREFIX_.'specific_price` WHERE `to` BETWEEN \''.$first_date.'\' AND \''.$last_date.'\'';
$to_specific_count = Db::getInstance(_PS_USE_SQL_SLAVE_)->getValue($query_to_count);
SpecificPrice::$_filterOutCache[$key] = array($from_specific_count, $to_specific_count);
} else {
list($from_specific_count, $to_specific_count) = SpecificPrice::$_filterOutCache[$key];
}
} else {
$from_specific_count = $to_specific_count = 1;
}

if ($from_specific_count) {
$query_extra .= ' AND (`from` = \'0000-00-00 00:00:00\' OR \''.$beginning.'\' >= `from`)';
} else {
$query_extra .= ' AND `from` = \'0000-00-00 00:00:00\'';
}

if ($to_specific_count) {
$query_extra .= ' AND (`to` = \'0000-00-00 00:00:00\' OR \''.$ending.'\' <= `to`)';
} else {
$query_extra .= ' AND `to` = \'0000-00-00 00:00:00\'';
}

return $query_extra;
}

private static function formatIntInQuery($first_value, $second_value) {

This comment has been minimized.

Copy link
@yelmontaser

yelmontaser Nov 5, 2015

idem.

$first_value = (int)$first_value;
$second_value = (int)$second_value;
if ($first_value != $second_value) {
return 'IN ('.$first_value.', '.$second_value.')';
} else {
return ' = '.$first_value;
}
}

public static function getSpecificPrice($id_product, $id_shop, $id_currency, $id_country, $id_group, $quantity, $id_product_attribute = null, $id_customer = 0, $id_cart = 0, $real_quantity = 0)
{
if (!SpecificPrice::isFeatureActive()) {
Expand All @@ -210,24 +338,15 @@ public static function getSpecificPrice($id_product, $id_shop, $id_currency, $id

$key = ((int)$id_product.'-'.(int)$id_shop.'-'.(int)$id_currency.'-'.(int)$id_country.'-'.(int)$id_group.'-'.(int)$quantity.'-'.(int)$id_product_attribute.'-'.(int)$id_cart.'-'.(int)$id_customer.'-'.(int)$real_quantity);
if (!array_key_exists($key, SpecificPrice::$_specificPriceCache)) {
$now = date('Y-m-d H:i:00');
$query_extra = self::computeExtraConditions($id_product, $id_product_attribute, $id_customer, $id_cart);
$query = '
SELECT *, '.SpecificPrice::_getScoreQuery($id_product, $id_shop, $id_currency, $id_country, $id_group, $id_customer).'
FROM `'._DB_PREFIX_.'specific_price` USE INDEX (id_product_2)
WHERE `id_product` IN (0, '.(int)$id_product.')
AND `id_product_attribute` IN (0, '.(int)$id_product_attribute.')
AND `id_shop` IN (0, '.(int)$id_shop.')
AND `id_currency` IN (0, '.(int)$id_currency.')
AND `id_country` IN (0, '.(int)$id_country.')
AND `id_group` IN (0, '.(int)$id_group.')
AND `id_customer` IN (0, '.(int)$id_customer.')
AND
(
(`from` = \'0000-00-00 00:00:00\' OR \''.$now.'\' >= `from`)
AND
(`to` = \'0000-00-00 00:00:00\' OR \''.$now.'\' <= `to`)
)
AND id_cart IN (0, '.(int)$id_cart.')
FROM `'._DB_PREFIX_.'specific_price`
WHERE
`id_shop` '.self::formatIntInQuery(0, $id_shop).' AND
`id_currency` '.self::formatIntInQuery(0, $id_currency).' AND
`id_country` '.self::formatIntInQuery(0, $id_country).' AND
`id_group` '.self::formatIntInQuery(0, $id_group).' '.$query_extra.'
AND IF(`from_quantity` > 1, `from_quantity`, 0) <= ';

$query .= (Configuration::get('PS_QTY_DISCOUNT_ON_COMBINATION') || !$id_cart || !$real_quantity) ? (int)$quantity : max(1, (int)$real_quantity);
Expand Down Expand Up @@ -279,25 +398,16 @@ public static function getQuantityDiscounts($id_product, $id_shop, $id_currency,
return array();
}

$now = date('Y-m-d H:i:00');
$query_extra = self::computeExtraConditions($id_product, ((!$all_combinations)?$id_product_attribute:null), $id_customer, null);
$result = Db::getInstance(_PS_USE_SQL_SLAVE_)->executeS('
SELECT *,
'.SpecificPrice::_getScoreQuery($id_product, $id_shop, $id_currency, $id_country, $id_group, $id_customer).'
FROM `'._DB_PREFIX_.'specific_price` USE INDEX (id_product_2)
FROM `'._DB_PREFIX_.'specific_price`
WHERE
`id_product` IN(0, '.(int)$id_product.') AND
'.(!$all_combinations ? '`id_product_attribute` IN(0, '.(int)$id_product_attribute.') AND ' : '').'
`id_shop` IN(0, '.(int)$id_shop.') AND
`id_currency` IN(0, '.(int)$id_currency.') AND
`id_country` IN(0, '.(int)$id_country.') AND
`id_group` IN(0, '.(int)$id_group.') AND
`id_customer` IN(0, '.(int)$id_customer.')
AND
(
(`from` = \'0000-00-00 00:00:00\' OR \''.$now.'\' >= `from`)
AND
(`to` = \'0000-00-00 00:00:00\' OR \''.$now.'\' <= `to`)
)
`id_shop` '.self::formatIntInQuery(0, $id_shop).' AND
`id_currency` '.self::formatIntInQuery(0, $id_currency).' AND
`id_country` '.self::formatIntInQuery(0, $id_country).' AND
`id_group` '.self::formatIntInQuery(0, $id_group).' '.$query_extra.'
ORDER BY `from_quantity` ASC, `id_specific_price_rule` ASC, `score` DESC, `to` DESC, `from` DESC
', false, false);

Expand Down Expand Up @@ -326,26 +436,19 @@ public static function getQuantityDiscount($id_product, $id_shop, $id_currency,
return array();
}

$now = date('Y-m-d H:i:00');


$query_extra = self::computeExtraConditions($id_product, $id_product_attribute, $id_customer, null);
return Db::getInstance(_PS_USE_SQL_SLAVE_)->getRow('
SELECT *,
'.SpecificPrice::_getScoreQuery($id_product, $id_shop, $id_currency, $id_country, $id_group, $id_customer).'
FROM `'._DB_PREFIX_.'specific_price` USE INDEX (id_product_2)
FROM `'._DB_PREFIX_.'specific_price`
WHERE
`id_product` IN(0, '.(int)$id_product.') AND
`id_product_attribute` IN(0, '.(int)$id_product_attribute.') AND
`id_shop` IN(0, '.(int)$id_shop.') AND
`id_currency` IN(0, '.(int)$id_currency.') AND
`id_country` IN(0, '.(int)$id_country.') AND
`id_group` IN(0, '.(int)$id_group.') AND
`id_customer` IN(0, '.(int)$id_customer.') AND
`from_quantity` >= '.(int)$quantity.'
AND
(
(`from` = \'0000-00-00 00:00:00\' OR \''.$now.'\' >= `from`)
AND
(`to` = \'0000-00-00 00:00:00\' OR \''.$now.'\' <= `to`)
)
`id_shop` '.self::formatIntInQuery(0, $id_shop).' AND
`id_currency` '.self::formatIntInQuery(0, $id_currency).' AND
`id_country` '.self::formatIntInQuery(0, $id_country).' AND
`id_group` '.self::formatIntInQuery(0, $id_group).' AND
`from_quantity` >= '.(int)$quantity.' '.$query_extra.'
ORDER BY `from_quantity` DESC, `score` DESC, `to` DESC, `from` DESC
');
}
Expand All @@ -356,26 +459,20 @@ public static function getProductIdByDate($id_shop, $id_currency, $id_country, $
return array();
}

$result = Db::getInstance(_PS_USE_SQL_SLAVE_)->executeS('
SELECT SQL_NO_CACHE `id_product`, `id_product_attribute`
$query_extra = self::computeExtraConditions(null, null, $id_customer, null, $beginning, $ending);
$results = Db::getInstance(_PS_USE_SQL_SLAVE_)->executeS('
SELECT `id_product`, `id_product_attribute`
FROM `'._DB_PREFIX_.'specific_price`
WHERE `id_shop` IN(0, '.(int)$id_shop.') AND
`id_currency` IN(0, '.(int)$id_currency.') AND
`id_country` IN(0, '.(int)$id_country.') AND
`id_group` IN(0, '.(int)$id_group.') AND
`id_customer` IN(0, '.(int)$id_customer.') AND
WHERE `id_shop` '.self::formatIntInQuery(0, $id_shop).' AND
`id_currency` '.self::formatIntInQuery(0, $id_currency).' AND
`id_country` '.self::formatIntInQuery(0, $id_country).' AND
`id_group` '.self::formatIntInQuery(0, $id_group).' AND
`from_quantity` = 1 AND
(
(`from` = \'0000-00-00 00:00:00\' OR \''.pSQL($beginning).'\' >= `from`)
AND
(`to` = \'0000-00-00 00:00:00\' OR \''.pSQL($ending).'\' <= `to`)
)
AND
`reduction` > 0
', false, false);
'.$query_extra);
$ids_product = array();
while ($row = Db::getInstance()->nextRow($result)) {
$ids_product[] = $with_combination_id ? array('id_product' => (int)$row['id_product'], 'id_product_attribute' => (int)$row['id_product_attribute']) : (int)$row['id_product'];
foreach($results as $key => $value) {
$ids_product[] = $with_combination_id ? array('id_product' => (int)$value['id_product'], 'id_product_attribute' => (int)$value['id_product_attribute']) : (int)$value['id_product'];
}

return $ids_product;
Expand Down
10 changes: 8 additions & 2 deletions install-dev/data/db_structure.sql
Expand Up @@ -367,7 +367,8 @@ CREATE TABLE `PREFIX_category_product` (
`id_product` int(10) unsigned NOT NULL,
`position` int(10) unsigned NOT NULL DEFAULT '0',
PRIMARY KEY (`id_category`,`id_product`),
INDEX (`id_product`)
INDEX (`id_product`),
INDEX (`id_category`, `position`)
) ENGINE=ENGINE_TYPE DEFAULT CHARSET=utf8 COLLATION;

CREATE TABLE `PREFIX_cms` (
Expand Down Expand Up @@ -1798,7 +1799,12 @@ CREATE TABLE `PREFIX_specific_price` (
KEY `from_quantity` (`from_quantity`),
KEY (`id_specific_price_rule`),
KEY (`id_cart`),
UNIQUE KEY `id_product_2` (`id_cart`, `id_product`,`id_shop`,`id_shop_group`,`id_currency`,`id_country`,`id_group`,`id_customer`,`id_product_attribute`,`from_quantity`,`id_specific_price_rule`,`from`,`to`)
KEY `id_product_attribute` (`id_product_attribute`),
KEY `id_shop` (`id_shop`),
KEY `id_customer` (`id_customer`),
KEY `from` (`from`),
KEY `to` (`to`),
UNIQUE KEY `id_product_2` (`id_product`,`id_product_attribute`,`id_customer`,`id_cart`,`from`,`to`,`id_shop`,`id_shop_group`,`id_currency`,`id_country`,`id_group`,`from_quantity`,`id_specific_price_rule`)
) ENGINE=ENGINE_TYPE DEFAULT CHARSET=utf8 COLLATION;

CREATE TABLE `PREFIX_state` (
Expand Down
9 changes: 9 additions & 0 deletions install-dev/upgrade/sql/1.6.1.2.sql
Expand Up @@ -24,5 +24,14 @@ REPLACE INTO `PREFIX_tag_count` (id_group, id_tag, id_lang, id_shop, counter)
TRUNCATE TABLE `PREFIX_smarty_last_flush`;

ALTER TABLE `PREFIX_search_index` ADD INDEX(`id_product`);
ALTER TABLE `PREFIX_specific_price` ADD INDEX(`id_product_attribute`);
ALTER TABLE `PREFIX_specific_price` ADD INDEX(`id_shop`);
ALTER TABLE `PREFIX_specific_price` ADD INDEX(`id_customer`);
ALTER TABLE `PREFIX_specific_price` ADD INDEX(`from`);
ALTER TABLE `PREFIX_specific_price` ADD INDEX(`to`);
ALTER TABLE `PREFIX_specific_price` DROP KEY `id_product_2`;
ALTER TABLE `PREFIX_specific_price` ADD UNIQUE KEY `id_product_2` (`id_product`,`id_product_attribute`,`id_customer`,`id_cart`,`from`,`to`,`id_shop`,`id_shop_group`,`id_currency`,`id_country`,`id_group`,`from_quantity`,`id_specific_price_rule`);
ALTER TABLE `PREFIX_category_product` ADD INDEX(`id_category`, `position`);


ALTER TABLE `PREFIX_address` CHANGE `company` `company` VARCHAR(64) NULL;

0 comments on commit c140d7a

Please sign in to comment.