diff --git a/application/controllers/Sales.php b/application/controllers/Sales.php index 91357d50c..b8f3e15d0 100644 --- a/application/controllers/Sales.php +++ b/application/controllers/Sales.php @@ -582,6 +582,21 @@ class Sales extends Secure_Controller } $data['amount_change'] = $data['amount_due'] * -1; + if($data['amount_change'] > 0) + { + // Save cash refund to the cash payment transaction if found, if not then add as new Cash transaction + + if(array_key_exists($this->lang->line('sales_cash'), $data['payments'])) + { + $data['payments'][$this->lang->line('sales_cash')]['cash_refund'] = $data['amount_change']; + } + else + { + $payment = array($this->lang->line('sales_cash') => array('payment_type' => $this->lang->line('sales_cash'), 'payment_amount' => 0, 'cash_refund' => $data['amount_change'])); + $data['payments'] += $payment; + } + } + $data['print_price_info'] = TRUE; $override_invoice_number = NULL; @@ -1281,7 +1296,7 @@ class Sales extends Secure_Controller // To maintain tradition we will also delete any payments with 0 amount assuming these are mistakes // introduced at sale time. This is now done in Sale.php - $payments[] = array('payment_id' => $payment_id, 'payment_type' => $payment_type, 'payment_amount' => $payment_amount, 'payment_user' => $employee_id); + $payments[] = array('payment_id' => $payment_id, 'payment_type' => $payment_type, 'payment_amount' => $payment_amount, 'employee_id' => $employee_id); } $payment_id = -1; @@ -1290,7 +1305,7 @@ class Sales extends Secure_Controller if($payment_type != PAYMENT_TYPE_UNASSIGNED && $payment_amount <> 0) { - $payments[] = array('payment_id' => $payment_id, 'payment_type' => $payment_type, 'payment_amount' => $payment_amount, 'payment_user' => $employee_id); + $payments[] = array('payment_id' => $payment_id, 'payment_type' => $payment_type, 'payment_amount' => $payment_amount, 'employee_id' => $employee_id); } if($this->Sale->update($sale_id, $sale_data, $payments)) diff --git a/application/libraries/Sale_lib.php b/application/libraries/Sale_lib.php index a9f65ed4f..8c7eec5ea 100644 --- a/application/libraries/Sale_lib.php +++ b/application/libraries/Sale_lib.php @@ -385,7 +385,7 @@ class Sale_lib else { //add to existing array - $payment = array($payment_id => array('payment_type' => $payment_id, 'payment_amount' => $payment_amount)); + $payment = array($payment_id => array('payment_type' => $payment_id, 'payment_amount' => $payment_amount, 'cash_refund' => 0)); $payments += $payment; } diff --git a/application/migrations/20190502100000_refundtracking.php b/application/migrations/20190502100000_refundtracking.php new file mode 100644 index 000000000..4bd94f296 --- /dev/null +++ b/application/migrations/20190502100000_refundtracking.php @@ -0,0 +1,110 @@ +lang->line('sales_cash'); + + $this->db->query('CREATE TEMPORARY TABLE IF NOT EXISTS ' . $this->db->dbprefix('migrate_taxes') . + ' (INDEX(sale_id)) + ( + SELECT sales.sale_id, SUM(sales_taxes.sale_tax_amount) AS total_taxes + FROM ' . $this->db->dbprefix('sales') . ' AS sales + LEFT OUTER JOIN ' . $this->db->dbprefix('sales_taxes') . ' AS sales_taxes + ON sales.sale_id = sales_taxes.sale_id + WHERE sales.sale_status = \'' . COMPLETED . '\' AND sales_taxes.tax_type = \'1\' + GROUP BY sale_id + )' + ); + + $this->db->query('CREATE TEMPORARY TABLE IF NOT EXISTS ' . $this->db->dbprefix('migrate_sales') . + ' (INDEX(sale_id)) + ( + SELECT sales.sale_id, '. $trans_amount . ', sales.employee_id, sales.sale_time' + . ' FROM ' . $this->db->dbprefix('sales') . ' AS sales ' + . 'LEFT OUTER JOIN ' . $this->db->dbprefix('sales_items') . ' AS sales_items ' + . 'ON sales.sale_id = sales_items.sale_id ' + . 'LEFT OUTER JOIN ' . $this->db->dbprefix('migrate_taxes') . ' AS sumpay_taxes ' + . 'ON sales.sale_id = sumpay_taxes.sale_id ' + . 'WHERE sales.sale_status = \'' . COMPLETED . '\' GROUP BY sale_id + )' + ); + + $this->db->query('UPDATE ' . $this->db->dbprefix('migrate_sales') . ' AS sumpay_items ' + . 'SET trans_amount = trans_amount + IFNULL((SELECT total_taxes FROM ' . $this->db->dbprefix('migrate_taxes') + . ' AS sumpay_taxes WHERE sumpay_items.sale_id = sumpay_taxes.sale_id),0)'); + + $this->db->query('CREATE TEMPORARY TABLE IF NOT EXISTS ' . $this->db->dbprefix('migrate_payments') . + ' (INDEX(sale_id)) + ( + SELECT sales.sale_id, COUNT(sales.sale_id) AS number_payments, + SUM(sales_payments.payment_amount - sales_payments.cash_refund) AS total_payments + FROM ' . $this->db->dbprefix('sales') . ' AS sales + LEFT OUTER JOIN ' . $this->db->dbprefix('sales_payments') . ' AS sales_payments + ON sales.sale_id = sales_payments.sale_id + WHERE sales.sale_status = \'' . COMPLETED . '\' GROUP BY sale_id + )' + ); + + // You may be asking yourself why the following is not creating a temporary table. + // It should be, it originallly was, but there is a bug in MySQL where temporary tables where some SQL statements fail. + // The update statement that follows this CREATE TABLE is one of those statements. + + $this->db->query('CREATE TABLE IF NOT EXISTS ' . $this->db->dbprefix('migrate_refund') . + ' (INDEX(sale_id)) + ( + select a.sale_id, total_payments - trans_amount as refund_amount + from ' . $this->db->dbprefix('migrate_sales') . ' as a + join ' . $this->db->dbprefix('migrate_payments') . ' as b on a.sale_id = b.sale_id + where total_payments > trans_amount and number_payments = 1 + )' + ); + + // Update existing cash transactions with refund amount + $this->db->query('update ' . $this->db->dbprefix('sales_payments') . ' as a + set a.cash_refund = + (select b.refund_amount + from ' . $this->db->dbprefix('migrate_refund') . ' as b + where a.sale_id = b.sale_id and a.payment_type = \'' . $cash_payment . '\') + where exists + (select b.refund_amount + from ' . $this->db->dbprefix('migrate_refund') . ' as b + where a.sale_id = b.sale_id and a.payment_type = \'' . $cash_payment . ' \')' + ); + + // Insert new cash refund transactions for non-cash payments + $this->db->query('insert into ' . $this->db->dbprefix('sales_payments') . + ' (sale_id, payment_type, employee_id, payment_time, payment_amount, cash_refund) + select r.sale_id, \'' . $cash_payment . '\', s.employee_id, sale_time, 0, r.refund_amount + from ' . $this->db->dbprefix('migrate_refund') . ' as r + join ' . $this->db->dbprefix('sales_payments') . ' as p on r.sale_id = p.sale_id + join ' . $this->db->dbprefix('migrate_sales') . ' as s on r.sale_id = s.sale_id + where p.payment_type != \'' . $cash_payment . '\'' + ); + + // Post migration cleanup + $this->db->query('DROP TABLE IF EXISTS ' . $this->db->dbprefix('migrate_refund')); + } + + public function down() + { + + } +} +?> diff --git a/application/migrations/sqlscripts/3.3.0_refundtracking.sql b/application/migrations/sqlscripts/3.3.0_refundtracking.sql new file mode 100644 index 000000000..dc626abb2 --- /dev/null +++ b/application/migrations/sqlscripts/3.3.0_refundtracking.sql @@ -0,0 +1,4 @@ +ALTER TABLE `ospos_sales_payments` + ADD COLUMN `cash_refund` decimal(15,2) NOT NULL DEFAULT 0 AFTER `payment_amount`, + CHANGE `payment_user` `employee_id` int(11) DEFAULT NULL, + CHANGE`payment_date` `payment_time` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP; diff --git a/application/models/Customer.php b/application/models/Customer.php index 1532f9913..04897c859 100644 --- a/application/models/Customer.php +++ b/application/models/Customer.php @@ -118,10 +118,10 @@ class Customer extends Person $quantity_decimals = quantity_decimals(); $this->db->select(' - SUM(sales_payments.payment_amount) AS total, - MIN(sales_payments.payment_amount) AS min, - MAX(sales_payments.payment_amount) AS max, - AVG(sales_payments.payment_amount) AS average, + SUM(sales_payments.payment_amount - sales_payments.cash_refund) AS total, + MIN(sales_payments.payment_amount - sales_payments.cash_refund) AS min, + MAX(sales_payments.payment_amount - sales_payments.cash_refund) AS max, + AVG(sales_payments.payment_amount - sales_payments.cash_refund) AS average, ' . " ROUND(AVG(sales_items_temp.avg_discount), $totals_decimals) AS avg_discount, ROUND(SUM(sales_items_temp.quantity), $quantity_decimals) AS quantity diff --git a/application/models/Sale.php b/application/models/Sale.php index 264e96ab3..b95df7a41 100644 --- a/application/models/Sale.php +++ b/application/models/Sale.php @@ -31,7 +31,7 @@ class Sale extends CI_Model ( SELECT payments.sale_id AS sale_id, IFNULL(SUM(payments.payment_amount), 0) AS sale_payment_amount, - GROUP_CONCAT(CONCAT(payments.payment_type, " ", payments.payment_amount) SEPARATOR ", ") AS payment_type + GROUP_CONCAT(CONCAT(payments.payment_type, " ", (payments.payment_amount - payments.cash_refund)) SEPARATOR ", ") AS payment_type FROM ' . $this->db->dbprefix('sales_payments') . ' AS payments INNER JOIN ' . $this->db->dbprefix('sales') . ' AS sales ON sales.sale_id = payments.sale_id @@ -146,7 +146,7 @@ class Sale extends CI_Model ( SELECT payments.sale_id AS sale_id, IFNULL(SUM(payments.payment_amount), 0) AS sale_payment_amount, - GROUP_CONCAT(CONCAT(payments.payment_type, " ", payments.payment_amount) SEPARATOR ", ") AS payment_type + GROUP_CONCAT(CONCAT(payments.payment_type, " ", (payments.payment_amount - payments.cash_refund)) SEPARATOR ", ") AS payment_type FROM ' . $this->db->dbprefix('sales_payments') . ' AS payments INNER JOIN ' . $this->db->dbprefix('sales') . ' AS sales ON sales.sale_id = payments.sale_id @@ -546,7 +546,8 @@ class Sale extends CI_Model $payment_id = $payment['payment_id']; $payment_type = $payment['payment_type']; $payment_amount = $payment['payment_amount']; - $payment_user = $payment['payment_user']; + $cash_refund = $payment['cash_refund']; + $employee_id = $payment['employee_id']; if($payment_id == - 1 && $payment_amount > 0) { @@ -555,7 +556,8 @@ class Sale extends CI_Model 'sale_id' => $sale_id, 'payment_type' => $payment_type, 'payment_amount' => $payment_amount, - 'payment_user' => $payment_user + 'cash_refund' => $cash_refund, + 'employee_id' => $employee_id ); $success = $this->db->insert('sales_payments', $sales_payments_data); } @@ -660,7 +662,8 @@ class Sale extends CI_Model 'sale_id' => $sale_id, 'payment_type' => $payment['payment_type'], 'payment_amount' => $payment['payment_amount'], - 'payment_user' => $employee_id + 'cash_refund' => $payment['cash_refund'], + 'employee_id' => $employee_id ); $this->db->insert('sales_payments', $sales_payments_data); @@ -1137,7 +1140,7 @@ class Sale extends CI_Model ( SELECT payments.sale_id AS sale_id, IFNULL(SUM(payments.payment_amount), 0) AS sale_payment_amount, - GROUP_CONCAT(CONCAT(payments.payment_type, " ", payments.payment_amount) SEPARATOR ", ") AS payment_type + GROUP_CONCAT(CONCAT(payments.payment_type, " ", (payments.payment_amount - payments.cash_refund)) SEPARATOR ", ") AS payment_type FROM ' . $this->db->dbprefix('sales_payments') . ' AS payments INNER JOIN ' . $this->db->dbprefix('sales') . ' AS sales ON sales.sale_id = payments.sale_id diff --git a/application/models/reports/Summary_payments.php b/application/models/reports/Summary_payments.php index 2e9c7eb3c..c1ed92f68 100644 --- a/application/models/reports/Summary_payments.php +++ b/application/models/reports/Summary_payments.php @@ -51,7 +51,7 @@ class Summary_payments extends Summary_report $select .= 'COUNT(sales.sale_id) AS trans_count, '; $select .= 'SUM(sumpay_items.trans_amount) AS trans_amount, '; $select .= 'IFNULL(SUM(sumpay_payments.total_payments),0) AS trans_payments, '; - $select .= 'SUM(CASE WHEN (IFNULL(sumpay_payments.total_payments,0) - sumpay_items.trans_amount) > 0 THEN IFNULL(sumpay_payments.total_payments,0) - sumpay_items.trans_amount ELSE 0 END) AS trans_refunded, '; + $select .= 'IFNULL(SUM(sumpay_payments.total_cash_refund),0) AS trans_refunded, '; $select .= 'SUM(CASE WHEN sumpay_items.trans_amount - IFNULL(sumpay_payments.total_payments,0) > 0 THEN sumpay_items.trans_amount - IFNULL(sumpay_payments.total_payments,0) ELSE 0 END) as trans_due '; $this->db->select($select); @@ -78,9 +78,9 @@ class Summary_payments extends Summary_report $select = '\'' . $this->lang->line('reports_trans_payments') . '\' AS trans_group, '; $select .= 'sales_payments.payment_type as trans_type, '; $select .= 'COUNT(sales.sale_id) AS trans_count, '; - $select .= 'SUM(payment_amount) AS trans_amount,'; + $select .= 'SUM(payment_amount - cash_refund) AS trans_amount,'; $select .= 'SUM(payment_amount) AS trans_payments,'; - $select .= '0 AS trans_refunded, '; + $select .= 'SUM(cash_refund) AS trans_refunded, '; $select .= '0 AS trans_due '; $this->db->select($select); @@ -93,16 +93,6 @@ class Summary_payments extends Summary_report $payments = $this->db->get()->result_array(); - // At this point in time refunds are assumed to be cash refunds. - foreach($payments as $key => $payment_summary) - { - if($payment_summary['trans_type'] == $cash_payment) - { - $payments[$key]['trans_refunded'] = $total_cash_refund; - $payments[$key]['trans_amount'] -= $total_cash_refund; - } - } - // consider Gift Card as only one type of payment and do not show "Gift Card: 1, Gift Card: 2, etc." in the total $gift_card_count = 0; $gift_card_amount = 0; @@ -135,7 +125,6 @@ class Summary_payments extends Summary_report . ' THEN sales_items.item_unit_price * sales_items.quantity_purchased * (1 - sales_items.discount / 100) ' . 'ELSE sales_items.item_unit_price * sales_items.quantity_purchased - sales_items.discount END), ' . $decimals . ') AS trans_amount'; - $this->db->query('CREATE TEMPORARY TABLE IF NOT EXISTS ' . $this->db->dbprefix('sumpay_taxes_temp') . ' (INDEX(sale_id)) ENGINE=MEMORY ( @@ -168,7 +157,8 @@ class Summary_payments extends Summary_report $this->db->query('CREATE TEMPORARY TABLE IF NOT EXISTS ' . $this->db->dbprefix('sumpay_payments_temp') . ' (INDEX(sale_id)) ENGINE=MEMORY ( - SELECT sales.sale_id, COUNT(sales.sale_id) AS number_payments, SUM(sales_payments.payment_amount) AS total_payments + SELECT sales.sale_id, COUNT(sales.sale_id) AS number_payments, SUM(sales_payments.payment_amount) AS total_payments, + SUM(sales_payments.cash_refund) AS total_cash_refund FROM ' . $this->db->dbprefix('sales') . ' AS sales LEFT OUTER JOIN ' . $this->db->dbprefix('sales_payments') . ' AS sales_payments ON sales.sale_id = sales_payments.sale_id