Including AR/AP accounts when doing manuelly Revaluation of Currency Accounts
authorJoe Hunt <joe.hunt.consulting@gmail.com>
Mon, 9 May 2011 13:30:53 +0000 (15:30 +0200)
committerJoe Hunt <joe.hunt.consulting@gmail.com>
Mon, 9 May 2011 13:30:53 +0000 (15:30 +0200)
gl/includes/db/gl_db_banking.inc

index 0801e90445fe5aab70f551408c140a0db92fb5f6..e4343a3b9f1eccecd8f5a81a5ce387715c73baa2 100644 (file)
@@ -49,6 +49,90 @@ function add_exchange_variation($trans_no, $date_, $acc_id, $account,
        return ($diff != 0);
 }
 
+//------------- New helper functions for revaluation of customer/supplier currencies 2011-05-08 Joe Hunt.
+function add_cust_supp_revaluation($ledger_act, $ex_act, $date, $amount, $person_type_id, $person_id, $memo)
+{
+       global $Refs;
+       if ($amount == 0)
+               return;
+       $trans_no = get_next_trans_no(ST_JOURNAL);
+       add_gl_trans(ST_JOURNAL, $trans_no, $date, $ledger_act, 0, 0, _("Exchange Variance"),
+               $amount, null, $person_type_id, $person_id);
+       add_gl_trans(ST_JOURNAL, $trans_no, $date, $ex_act, 0, 0, 
+               _("Exchange Variance"), -$amount, null, $person_type_id, $person_id);
+       add_comments(ST_JOURNAL, $trans_no, $date, $memo);
+       $ref = $Refs->get_next(ST_JOURNAL);
+       $Refs->save(ST_JOURNAL, $trans_no, $ref);
+       add_audit_trail(ST_JOURNAL, $trans_no, $date);
+}
+
+function get_cust_account_curr_balances($date)
+{
+       $to = date2sql($date);
+
+    $sql = "SELECT SUM(IF(t.type =".ST_CUSTCREDIT." OR t.type = ".ST_CUSTPAYMENT." OR t.type = ".ST_BANKDEPOSIT.",
+                       -(t.ov_amount + t.ov_gst + t.ov_freight + t.ov_freight_tax + t.ov_discount), 
+               (t.ov_amount + t.ov_gst + t.ov_freight + t.ov_freight_tax + t.ov_discount))) AS amount,
+               dt.debtor_no, dt.name, dt.curr_code, b.receivables_account
+               FROM ".TB_PREF."debtor_trans t 
+                       LEFT JOIN ".TB_PREF."debtors_master dt ON t.debtor_no = dt.debtor_no
+                       LEFT JOIN ".TB_PREF."cust_branch b ON t.debtor_no = b.debtor_no
+                       LEFT JOIN ".TB_PREF."voided as v ON v.type = t.type and v.id=t.trans_no
+       WHERE ISNULL(v.date_) AND t.type <> ".ST_CUSTDELIVERY." AND t.tran_date <= '$to' 
+               AND t.branch_code=b.branch_code AND dt.curr_code<>'".get_company_pref('curr_default')."' 
+               GROUP BY t.debtor_no, b.receivables_account";
+
+    $result = db_query($sql,"Open balances in foreign currency for cannot be retrieved");
+       return  $result;
+}
+
+function get_cust_account_home_balance($debtor_no, $rec_account, $to_date)
+{
+       $to = date2sql($to_date);
+
+    $sql = "SELECT SUM(amount) FROM ".TB_PREF."gl_trans t  
+       LEFT JOIN ".TB_PREF."debtors_master d ON t.person_id = d.debtor_no
+       LEFT JOIN ".TB_PREF."debtor_trans dt ON (t.type=dt.type AND t.type_no=dt.trans_no) 
+       LEFT JOIN ".TB_PREF."cust_branch br ON dt.branch_code = br.branch_code
+                       WHERE br.debtor_no=".db_escape($debtor_no)." AND t.account=br.receivables_account AND t.account='$rec_account' 
+                       AND person_id=br.debtor_no AND person_type_id=".PT_CUSTOMER." 
+                       AND t.tran_date <= '$to'";
+       $result = db_query($sql, "The AR balance for customer $debtor_no could not be calculated");
+       $row = db_fetch_row($result);
+       return $row[0];
+}
+
+function get_supp_account_curr_balances($date)
+{
+       $to = date2sql($date);
+
+    $sql = "SELECT SUM(-(t.ov_amount + t.ov_gst + t.ov_discount)) AS amount,
+               supp.supplier_id, supp.supp_name, supp.curr_code, supp.payable_account
+               FROM ".TB_PREF."supp_trans t 
+                       LEFT JOIN ".TB_PREF."suppliers supp ON t.supplier_id = supp.supplier_id
+                       LEFT JOIN ".TB_PREF."voided as v ON v.type = t.type and v.id=t.trans_no
+       WHERE ISNULL(v.date_) AND t.tran_date <= '$to' 
+               AND supp.curr_code<>'".get_company_pref('curr_default')."' 
+               GROUP BY t.supplier_id";
+
+    $result = db_query($sql,"Open balances in foreign currency for cannot be retrieved");
+       return  $result;
+}
+
+function get_supp_account_home_balance($supplier_id, $rec_account, $to_date)
+{
+       $to = date2sql($to_date);
+
+    $sql = "SELECT SUM(amount) FROM ".TB_PREF."gl_trans t  
+                       WHERE t.person_id=".db_escape($supplier_id)." AND t.account='$rec_account' 
+                       AND person_type_id=".PT_SUPPLIER." AND t.tran_date <= '$to'";
+       $result = db_query($sql, "The AP balance for customer $supplier_id could not be calculated");
+       $row = db_fetch_row($result);
+       return $row[0];
+}
+//------------- New helper functions for revaluation of customer/supplier currencies 2011-05-08 Joe Hunt.
+
+
 function add_exchange_variation_all($date=null, $ref="", $memo)
 {
        global $Refs;
@@ -71,6 +155,43 @@ function add_exchange_variation_all($date=null, $ref="", $memo)
                $Refs->save(ST_JOURNAL, $trans_no, $ref);
                add_audit_trail(ST_JOURNAL, $trans_no, $date);
        }       
+
+       //------------- BEGIN inserted for revaluation of customer/supplier currencies 2011-05-08 Joe Hunt.
+       if ($date == null)
+               $date = Today();
+       // debtors
+       $exchange_act = get_company_pref('exchange_diff_act');
+       $res = get_cust_account_curr_balances($date);
+       
+       while($row = db_fetch($res)) 
+       {
+               $exrate = get_exchange_rate_from_home_currency($row['curr_code'], $date);
+               $foreign = round2($row['amount']*$exrate, user_price_dec());
+               $home = round2(get_cust_account_home_balance($row['debtor_no'], $row['receivables_account'], $date), user_price_dec());
+               if ($foreign != $home) 
+               {
+                       $amount = $foreign - $home;     
+                       add_cust_supp_revaluation($row['receivables_account'], $exchange_act, $date, $amount, PT_CUSTOMER, 
+                               $row['debtor_no'], $memo);
+               }
+       }
+       // creditors
+       $res = get_supp_account_curr_balances($date);
+       
+       while($row = db_fetch($res)) 
+       {
+               $exrate = get_exchange_rate_from_home_currency($row['curr_code'], $date);
+               $foreign = round2($row['amount']*$exrate, user_price_dec());
+               $home = round2(get_supp_account_home_balance($row['supplier_id'], $row['payable_account'], $date), user_price_dec());
+               if ($foreign != $home) 
+               {
+                       $amount = $foreign - $home;     
+                       add_cust_supp_revaluation($row['payable_account'], $exchange_act, $date, $amount, PT_SUPPLIER, 
+                               $row['supplier_id'], $memo);
+               }
+       }
+       //------------- END
+       
        commit_transaction();
        return ($exchanged ? $trans_no : 0);
 }