Improved journal trans: added currency support, tax and source document date. Allowed...
[fa-stable.git] / sales / includes / db / customers_db.inc
1 <?php
2 /**********************************************************************
3     Copyright (C) FrontAccounting, LLC.
4         Released under the terms of the GNU General Public License, GPL, 
5         as published by the Free Software Foundation, either version 3 
6         of the License, or (at your option) any later version.
7     This program is distributed in the hope that it will be useful,
8     but WITHOUT ANY WARRANTY; without even the implied warranty of
9     MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  
10     See the License here <http://www.gnu.org/licenses/gpl-3.0.html>.
11 ***********************************************************************/
12
13 function add_customer($CustName, $cust_ref, $address, $tax_id, $curr_code,
14         $dimension_id, $dimension2_id, $credit_status, $payment_terms, $discount, $pymt_discount, 
15         $credit_limit, $sales_type, $notes)
16 {
17         $sql = "INSERT INTO ".TB_PREF."debtors_master (name, debtor_ref, address, tax_id,
18                 dimension_id, dimension2_id, curr_code, credit_status, payment_terms, discount, 
19                 pymt_discount,credit_limit, sales_type, notes) VALUES ("
20                 .db_escape($CustName) .", " .db_escape($cust_ref) .", "
21                 .db_escape($address) . ", " . db_escape($tax_id) . ","
22                 .db_escape($dimension_id) . ", " 
23                 .db_escape($dimension2_id) . ", ".db_escape($curr_code) . ", 
24                 " . db_escape($credit_status) . ", ".db_escape($payment_terms) . ", " . $discount . ", 
25                 " . $pymt_discount . ", " . $credit_limit 
26                  .", ".db_escape($sales_type).", ".db_escape($notes) . ")";
27         db_query($sql,"The customer could not be added");
28 }
29
30 function update_customer($customer_id, $CustName, $cust_ref, $address, $tax_id, $curr_code,
31         $dimension_id, $dimension2_id, $credit_status, $payment_terms, $discount, $pymt_discount,
32         $credit_limit, $sales_type, $notes)
33 {
34         $sql = "UPDATE ".TB_PREF."debtors_master SET name=" . db_escape($CustName) . ", 
35                 debtor_ref=" . db_escape($cust_ref) . ",
36                 address=".db_escape($address) . ", 
37                 tax_id=".db_escape($tax_id) . ", 
38                 curr_code=".db_escape($curr_code) . ", 
39                 dimension_id=".db_escape($dimension_id) . ", 
40                 dimension2_id=".db_escape($dimension2_id) . ", 
41                 credit_status=".db_escape($credit_status) . ", 
42                 payment_terms=".db_escape($payment_terms) . ", 
43                 discount=" . $discount . ", 
44                 pymt_discount=" . $pymt_discount . ", 
45                 credit_limit=" . $credit_limit . ", 
46                 sales_type = ".db_escape($sales_type) . ", 
47                 notes=".db_escape($notes) ."
48                 WHERE debtor_no = ".db_escape($customer_id);
49
50         db_query($sql,"The customer could not be updated");
51 }
52
53 function delete_customer($customer_id)
54 {
55         begin_transaction();
56         delete_entity_contacts('customer', $customer_id);
57
58         $sql = "DELETE FROM ".TB_PREF."debtors_master WHERE debtor_no=".db_escape($customer_id);;
59         db_query($sql,"cannot delete customer");
60         commit_transaction();
61 }
62
63 function get_customer_details($customer_id, $to=null, $all=true)
64 {
65
66         if ($to == null)
67                 $todate = date("Y-m-d");
68         else
69                 $todate = date2sql($to);
70         $past1 = get_company_pref('past_due_days');
71         $past2 = 2 * $past1;
72         // removed - debtor_trans.alloc from all summations
73         $sign = "IF(`type` IN(".implode(',',  array(ST_CUSTCREDIT,ST_CUSTPAYMENT,ST_BANKDEPOSIT,ST_JOURNAL))."), -1, 1)";
74         if ($all)
75         $value = "IFNULL($sign*(trans.ov_amount + trans.ov_gst + trans.ov_freight + trans.ov_freight_tax + trans.ov_discount),0)";
76     else                
77         $value = "IFNULL($sign*(trans.ov_amount + trans.ov_gst + trans.ov_freight + trans.ov_freight_tax + trans.ov_discount - 
78                 trans.alloc),0)";
79         $due = "IF (trans.type=10, trans.due_date, trans.tran_date)";
80     $sql = "SELECT ".TB_PREF."debtors_master.name, ".TB_PREF."debtors_master.curr_code, ".TB_PREF."payment_terms.terms,
81                 ".TB_PREF."debtors_master.credit_limit, ".TB_PREF."credit_status.dissallow_invoices, ".TB_PREF."credit_status.reason_description,
82
83                 Sum(IFNULL($value,0)) AS Balance,
84                 Sum(IF ((TO_DAYS('$todate') - TO_DAYS($due)) > 0,$value,0)) AS Due,
85                 Sum(IF ((TO_DAYS('$todate') - TO_DAYS($due)) > $past1,$value,0)) AS Overdue1,
86                 Sum(IF ((TO_DAYS('$todate') - TO_DAYS($due)) > $past2,$value,0)) AS Overdue2
87
88                 FROM ".TB_PREF."debtors_master
89                          LEFT JOIN ".TB_PREF."debtor_trans trans ON 
90                          trans.tran_date <= '$todate' AND ".TB_PREF."debtors_master.debtor_no = trans.debtor_no AND trans.type <> 13
91 ,
92                          ".TB_PREF."payment_terms,
93                          ".TB_PREF."credit_status
94
95                 WHERE
96                          ".TB_PREF."debtors_master.payment_terms = ".TB_PREF."payment_terms.terms_indicator
97                          AND ".TB_PREF."debtors_master.credit_status = ".TB_PREF."credit_status.id
98                          AND ".TB_PREF."debtors_master.debtor_no = ".db_escape($customer_id)." ";
99         if (!$all)
100                 $sql .= "AND ABS(trans.ov_amount + trans.ov_gst + trans.ov_freight + trans.ov_freight_tax + trans.ov_discount - trans.alloc) > ".FLOAT_COMP_DELTA." ";  
101         $sql .= "GROUP BY
102                           ".TB_PREF."debtors_master.name,
103                           ".TB_PREF."payment_terms.terms,
104                           ".TB_PREF."payment_terms.days_before_due,
105                           ".TB_PREF."payment_terms.day_in_following_month,
106                           ".TB_PREF."debtors_master.credit_limit,
107                           ".TB_PREF."credit_status.dissallow_invoices,
108                           ".TB_PREF."credit_status.reason_description";
109     $result = db_query($sql,"The customer details could not be retrieved");
110
111     $customer_record = db_fetch($result);
112
113     return $customer_record;
114
115 }
116
117
118 function get_customer($customer_id)
119 {
120         $sql = "SELECT * FROM ".TB_PREF."debtors_master WHERE debtor_no=".db_escape($customer_id);
121
122         $result = db_query($sql, "could not get customer");
123
124         return db_fetch($result);
125 }
126
127 function get_customer_name($customer_id)
128 {
129         $sql = "SELECT name FROM ".TB_PREF."debtors_master WHERE debtor_no=".db_escape($customer_id);
130
131         $result = db_query($sql, "could not get customer");
132
133         $row = db_fetch_row($result);
134
135         return $row[0];
136 }
137
138 function get_customer_habit($customer_id)
139 {
140         $sql = "SELECT ".TB_PREF."debtors_master.pymt_discount,
141                 ".TB_PREF."credit_status.dissallow_invoices
142                 FROM ".TB_PREF."debtors_master, ".TB_PREF."credit_status
143                 WHERE ".TB_PREF."debtors_master.credit_status = ".TB_PREF."credit_status.id
144                         AND ".TB_PREF."debtors_master.debtor_no = ".db_escape($customer_id);
145
146         $result = db_query($sql, "could not query customers");
147
148         return db_fetch($result);
149 }
150
151 function get_customer_contacts($customer_id, $action=null)
152 {
153         $results = array();
154         $res = get_crm_persons('customer', $action, $customer_id);
155         while($contact = db_fetch($res))
156         {
157                 if ($contact['lang'] == 'C') // Fix for improper lang in demo sql files.
158                         $contact['lang'] = '';
159                 $results[] = $contact;
160         }       
161         return $results;
162 }
163
164 function get_current_cust_credit($customer_id)
165 {
166         $custdet = get_customer_details($customer_id);
167
168         return $custdet['credit_limit']-$custdet['Balance'];
169
170 }
171
172 function is_new_customer($id)
173 {
174         $tables = array('cust_branch', 'debtor_trans', 'recurrent_invoices', 'sales_orders');
175
176         return !key_in_foreign_table($id, $tables, 'debtor_no');
177 }
178
179 function get_customer_by_ref($reference)
180 {
181         $sql = "SELECT * FROM ".TB_PREF."debtors_master WHERE debtor_ref=".db_escape($reference);
182
183         $result = db_query($sql, "could not get customer");
184
185         return db_fetch($result);
186 }
187
188 //----------------------------------------------------------------------------------
189
190 function get_customer_currency($customer_id=null, $branch_id=null)
191 {
192     $sql = "SELECT curr_code FROM ".TB_PREF."debtors_master cust
193                 LEFT JOIN ".TB_PREF."cust_branch branch ON branch.debtor_no=cust.debtor_no
194         WHERE " .(isset($branch_id) ? "branch_code = ".db_escape($branch_id) : "cust.debtor_no = ".db_escape($customer_id));
195
196         $result = db_query($sql, "Retreive currency of customer $customer_id");
197
198         $myrow=db_fetch_row($result);
199         return $myrow[0];
200 }
201