Post by OpenM » Wed Dec 05, 2012 5:00 am

I'm having trouble generating sales report

Dedicated Server on Dreamhost: 4GB dual core
OC 1.5.1 and MySQL Otimized

The application generates many slow MySql queries like these:

Executed 16 min ago for 202 sec on Database --> unknown.

Code: Select all

SELECT MIN(tmp.date_added) AS date_start, MAX(tmp.date_added) AS date_end, COUNT(tmp.order_id) AS `orders`, SUM(tmp.products) AS products, SUM(tmp.tax) AS tax, SUM(tmp.total) AS total FROM (SELECT o.order_id, (SELECT SUM(op.quantity) FROM `oc_order_product` op WHERE op.order_id = o.order_id GROUP BY op.order_id) AS products, (SELECT SUM(ot.value) FROM `oc_order_total` ot WHERE ot.order_id = o.order_id AND ot.code = 'tax' GROUP BY ot.order_id) AS tax, o.total, o.date_added FROM `oc_order` o WHERE o.order_status_id = '0' GROUP BY o.order_id) tmp GROUP BY WEEK(tmp.date_added) LIMIT 0,50

Newbie

Posts

Joined
Sun Aug 14, 2011 2:34 am

Post by OpenM » Thu Dec 06, 2012 12:14 am

Help!

Newbie

Posts

Joined
Sun Aug 14, 2011 2:34 am

Post by OpenM » Wed Dec 12, 2012 8:30 am

UP

Newbie

Posts

Joined
Sun Aug 14, 2011 2:34 am

Post by OpenM » Thu Dec 20, 2012 5:15 am

UP!

Newbie

Posts

Joined
Sun Aug 14, 2011 2:34 am

Post by ksharlandjiev » Wed Jan 09, 2013 6:25 pm

This is because of the nature of the query itself.... Too many inner selects, too many group by statements, which broke any table keys/indexes.....
Here is a solution:
Open your admin/model/report/sale.php file
Find this code:

Code: Select all

	public function getOrders($data = array()) {
		$sql = "SELECT MIN(tmp.date_added) AS date_start, MAX(tmp.date_added) AS date_end, COUNT(tmp.order_id) AS `orders`, SUM(tmp.products) AS products, SUM(tmp.tax) AS tax, SUM(tmp.total) AS total FROM (SELECT o.order_id, (SELECT SUM(op.quantity) FROM `" . DB_PREFIX . "order_product` op WHERE op.order_id = o.order_id GROUP BY op.order_id) AS products, (SELECT SUM(ot.value) FROM `" . DB_PREFIX . "order_total` ot WHERE ot.order_id = o.order_id AND ot.code = 'tax' GROUP BY ot.order_id) AS tax, o.total, o.date_added FROM `" . DB_PREFIX . "order` o"; 

		if (isset($data['filter_order_status_id']) && $data['filter_order_status_id']) {
			$sql .= " WHERE o.order_status_id = '" . (int)$data['filter_order_status_id'] . "'";
		} else {
			$sql .= " WHERE o.order_status_id > '0'";
		}
		
		if (isset($data['filter_date_start']) && $data['filter_date_start']) {
			$sql .= " AND DATE(o.date_added) >= '" . $this->db->escape($data['filter_date_start']) . "'";
		}

		if (isset($data['filter_date_end']) && $data['filter_date_end']) {
			$sql .= " AND DATE(o.date_added) <= '" . $this->db->escape($data['filter_date_end']) . "'";
		}
		
		$sql .= " GROUP BY o.order_id) tmp";
		
		if (isset($data['filter_group'])) {
			$group = $data['filter_group'];
		} else {
			$group = 'week';
		}
		
		switch($group) {
			case 'day';
				$sql .= " GROUP BY DAY(tmp.date_added)";
				break;
			default:
			case 'week':
				$sql .= " GROUP BY WEEK(tmp.date_added)";
				break;	
			case 'month':
				$sql .= " GROUP BY MONTH(tmp.date_added)";
				break;
			case 'year':
				$sql .= " GROUP BY YEAR(tmp.date_added)";
				break;									
		}
		
		if (isset($data['start']) || isset($data['limit'])) {
			if ($data['start'] < 0) {
				$data['start'] = 0;
			}			

			if ($data['limit'] < 1) {
				$data['limit'] = 20;
			}	
			
			$sql .= " LIMIT " . (int)$data['start'] . "," . (int)$data['limit'];
		}	
		echo $sql;
		exit;
		
		$query = $this->db->query($sql);
		
		return $query->rows;
	}
And replace it with this one:

Code: Select all

	public function getOrders($data = array()) {	 
	 $sql="";
		if (isset($data['filter_order_status_id']) && $data['filter_order_status_id']) {
			$sql .= " WHERE o.order_status_id = '" . (int)$data['filter_order_status_id'] . "'";
		} else {
			$sql .= " WHERE o.order_status_id > '0'";
		}
		
		if (isset($data['filter_date_start']) && $data['filter_date_start']) {
			$sql .= " AND DATE(o.date_added) >= '" . $this->db->escape($data['filter_date_start']) . "'";
		}

		if (isset($data['filter_date_end']) && $data['filter_date_end']) {
			$sql .= " AND DATE(o.date_added) <= '" . $this->db->escape($data['filter_date_end']) . "'";
		}
		
  	if (isset($data['filter_group'])) {
			$group = $data['filter_group'];
		} else {
			$group = 'week';
		}
		$key='';
		switch($group) {
			case 'day';
				$sql .= " GROUP BY DAY(o.date_added)";
				$key = "DAY(o.date_added) as ukey,";
				break;
			default:
			case 'week':
				$sql .= " GROUP BY WEEK(o.date_added)";
				$key = "  WEEK(o.date_added) as ukey,";
				break;	
			case 'month':
				$sql .= " GROUP BY MONTH(o.date_added)";
				$key = "  MONTH(o.date_added) as ukey,";
				break;
			case 'year':
				$sql .= " GROUP BY YEAR(o.date_added)";
				$key = "  YEAR(o.date_added) as ukey,";				
				break;									
		}		
		$sql .= " LIMIT " . (int)$data['start'] . "," . (int)$data['limit'];
		$sql2 = "SELECT ".$key." o.order_id, MIN(o.date_added) as min_date, MAX(o.date_added) as max_date, COUNT(o.order_id) as cnt_orders, SUM(o.total) as total FROM `".DB_PREFIX."order` o";
		$query = $this->db->query($sql2.$sql);
		$data = array();
		$data2 = array();
		$theData = array();
		foreach ($query->rows as $row) {
  		  $data[$row['ukey']] = array (
  		    'date_start'  => $row['min_date'],
  		    'date_end'    => $row['max_date'],
  		    'orders'      => $row['cnt_orders'],
  		    'total'       => $row['total'],
  		    'products'    => null,
  		    'tax'         => null,
  		    
  		  );  		
		}
    $sql2 = "SELECT ".$key." op.order_id, SUM(op.quantity) as products FROM ".DB_PREFIX."order_product op LEFT JOIN `".DB_PREFIX."order` o ON (op.order_id=o.order_id)" ;
    
    $query = $this->db->query($sql2.$sql);
    foreach ($query->rows as $row) {
        $data[$row['ukey']]['products'] = $row['products'];
    }
    
    $sql2 = "SELECT ".$key."ot.order_id, SUM(ot.value) as tax FROM ".DB_PREFIX."order_total ot LEFT JOIN `".DB_PREFIX."order` o ON ( o.order_id=ot.order_id AND ot.code='tax')";    
    $query=$this->db->query($sql2.$sql);
    foreach ($query->rows as $row) {
        $data[$row['ukey']]['tax'] = $row['tax'];
    }    
		return $data;
}
Let me know of the result :)

Power Image Manager | Multi Image uploader | Bulk Update Products to Categories | Bulk Update Orders
Image
NEW! Bulk add options | New! Bulk add attributes | NEW! Keep it Simple Checkout!


User avatar
Active Member

Posts

Joined
Sun Oct 09, 2011 9:22 pm
Location - London, UK

Post by nholliss » Tue Oct 28, 2014 5:01 am

This is great - thanks so much!

The only difference is that it displays the oldest weeks first, and the latest weeks last.

Is there a simple fix for this? I'm so used to seeing the latest week first it's weird it being the other way.

Great though! Gone down from 2 minutes to load (prior code) to 5 seconds (new code)

N

Newbie

Posts

Joined
Tue Oct 28, 2014 4:58 am

Post by speelgoed14 » Mon Feb 27, 2017 6:53 am

Thanks a lot ksharlandjiev! This helped us enormously! We never had any problems with loading the sales reports, but suddenly on one day I think we hit the maximum server CPU capacity (could see it in the CPU usage graphs). Your fix works like a charm! With the Kind regards, Joost

Newbie

Posts

Joined
Mon Nov 11, 2013 7:42 pm
Who is online

Users browsing this forum: No registered users and 130 guests