477002a000c242e61bc778558f119d2be5d9291f
[fa-stable.git] / sales / includes / db / custalloc_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
14 function add_cust_allocation($amount, $trans_type_from, $trans_no_from,
15         $trans_type_to, $trans_no_to)
16 {
17         $sql = "INSERT INTO ".TB_PREF."cust_allocations (
18                 amt, date_alloc,
19                 trans_type_from, trans_no_from, trans_no_to, trans_type_to)
20                 VALUES ($amount, Now(), ".db_escape($trans_type_from).", ".db_escape($trans_no_from).", ".db_escape($trans_no_to)
21                 .", ".db_escape($trans_type_to).")";
22
23         db_query($sql, "A customer allocation could not be added to the database");
24 }
25
26 //----------------------------------------------------------------------------------------
27
28
29 function delete_cust_allocation($trans_id)
30 {
31         $sql = "DELETE FROM ".TB_PREF."cust_allocations WHERE id = ".db_escape($trans_id);
32         return db_query($sql, "The existing allocation $trans_id could not be deleted");
33 }
34
35 //----------------------------------------------------------------------------------------
36 //      Update debtor trans alloc field according to current status of cust_allocations
37 //
38 function update_debtor_trans_allocation($trans_type, $trans_no)
39 {
40         $sql = "UPDATE `".TB_PREF."debtor_trans` trans,
41                         (SELECT sum(amt) amt from ".TB_PREF."cust_allocations
42                                 WHERE (trans_type_to=".db_escape($trans_type)." AND trans_no_to=".db_escape($trans_no).")
43                                 OR (trans_type_from=".db_escape($trans_type)." AND trans_no_from=".db_escape($trans_no).")) allocated
44                 SET 
45                         trans.alloc=IFNULL(allocated.amt,0)
46                 WHERE trans.type=".db_escape($trans_type)." AND trans_no=".db_escape($trans_no);
47
48         db_query($sql, "The debtor transaction record could not be modified for the allocation against it");
49 }
50
51 function get_cust_allocation($trans_id)
52 {
53         $sql = "SELECT * FROM ".TB_PREF."cust_allocations WHERE id = ".db_escape($trans_id);
54         return db_fetch(db_query($sql), "Cannot retrieve customer allocation $trans_id");
55 }
56
57 //-------------------------------------------------------------------------------------------------------------
58
59 function void_cust_allocations($type, $type_no, $date="")
60 {
61         return clear_cust_alloctions($type, $type_no, $date);
62 }
63
64 //-------------------------------------------------------------------------------------------------------------
65
66 function clear_cust_alloctions($type, $type_no, $date="")
67 {
68         $sql = "UPDATE  ".TB_PREF."cust_allocations ca
69                                 LEFT JOIN ".TB_PREF."debtor_trans paym ON ca.trans_type_from=paym.type AND ca.trans_no_from=paym.trans_no
70                                 LEFT JOIN ".TB_PREF."debtor_trans dt ON ca.trans_type_to=dt.type AND ca.trans_no_to=dt.trans_no
71                                 LEFT JOIN ".TB_PREF."sales_orders so ON ca.trans_type_to=so.trans_type AND ca.trans_no_to=so.order_no
72                         SET paym.alloc=paym.alloc - ca.amt,
73                                 dt.alloc=dt.alloc -  ca.amt,
74                                 so.alloc=so.alloc -  ca.amt
75                         WHERE  (ca.trans_type_from=".db_escape($type)." AND ca.trans_no_from=".db_escape($type_no).")
76                                 OR (ca.trans_type_to=".db_escape($type)." AND ca.trans_no_to=".db_escape($type_no).")";
77                 db_query($sql, "could not clear allocation");
78
79         // remove any allocations for this transaction
80         $sql = "DELETE FROM ".TB_PREF."cust_allocations
81                         WHERE  (trans_type_from=".db_escape($type)." AND trans_no_from=".db_escape($type_no).")
82                                 OR (trans_type_to=".db_escape($type)." AND trans_no_to=".db_escape($type_no).")";
83
84         db_query($sql, "could not void debtor transactions for type=$type and trans_no=$type_no");
85 // is this necessary?
86 //      if ($date != "")
87 //              exchange_variation($type, $type_no, $row['trans_type_to'], $row['trans_no_to'], $date,
88 //                      $row['amt'], PT_CUSTOMER, true);
89 }
90 //-------------------------------------------------------------------------------------------------------------
91
92 function get_allocatable_from_cust_sql($customer_id=null, $settled)
93 {
94         $sql = "SELECT
95                 trans.type,
96                 trans.trans_no,
97                 trans.reference,
98                 trans.tran_date,
99                 debtor.name AS DebtorName, 
100                 debtor.curr_code,
101                 ov_amount+ov_gst+ov_freight+ov_freight_tax+ov_discount AS Total,
102                 trans.alloc,
103                 trans.due_date,
104                 debtor.address,
105                 trans.version,
106                 round(abs(ov_amount+ov_gst+ov_freight+ov_freight_tax+ov_discount-alloc),6) <= 0 AS settled,
107                 trans.debtor_no
108          FROM "
109                 .TB_PREF."debtor_trans as trans, "
110                 .TB_PREF."debtors_master as debtor"
111         ." WHERE trans.debtor_no=debtor.debtor_no
112                 AND (((type=".ST_CUSTPAYMENT." OR type=".ST_BANKDEPOSIT.") AND (trans.ov_amount > 0))"
113                 ." OR (type=".ST_CUSTCREDIT." AND (ov_amount+ov_gst+ov_freight+ov_freight_tax+ov_discount)>0))";
114
115         if (!$settled)
116                 $sql .= " AND (round(abs(ov_amount+ov_gst+ov_freight+ov_freight_tax-ov_discount-alloc),6) > 0)";
117
118         if ($customer_id != null)
119                 $sql .= " AND trans.debtor_no = ".db_escape($customer_id);
120
121         return $sql;
122 }
123
124 function get_allocatable_sales_orders($customer_id = null, $trans_no=null, $type=null)
125 {
126         $sql = "SELECT
127                 sorder.trans_type as type,
128                 sorder.order_no as trans_no,
129                 sorder.reference,
130                 sorder.ord_date,
131                 debtor.name AS DebtorName, 
132                 debtor.curr_code,
133                 total-IFNULL(invoiced.amount,0) as Total,
134                 sorder.alloc,
135                 sorder.delivery_date as due_date,
136                 debtor.address,
137                 sorder.version,
138                 amt
139                 FROM ".TB_PREF."sales_orders as sorder
140                         LEFT JOIN ".TB_PREF."debtors_master as debtor ON sorder.debtor_no = debtor.debtor_no
141                         LEFT JOIN ".TB_PREF."cust_allocations as alloc ON sorder.order_no = alloc.trans_no_to AND sorder.trans_type = alloc.trans_type_to
142                         LEFT JOIN (SELECT order_, sum(prep_amount) amount FROM ".TB_PREF."debtor_trans dt
143                         WHERE prep_amount>0 AND dt.type=".ST_SALESINVOICE." GROUP BY order_) as invoiced ON sorder.order_no = invoiced.order_
144                 WHERE sorder.trans_type=".ST_SALESORDER;
145
146         if ($trans_no != null and $type != null)
147         {
148                 $sql .= " AND alloc.trans_no_from=".db_escape($trans_no)."
149                                   AND alloc.trans_type_from=".db_escape($type);
150         }
151         else
152         {
153                 $sql .= " AND round(sorder.prep_amount)>0 and Total>0"; // only sales orders with prepayment level set and no yet fully invoiced
154         }
155         if ($customer_id)
156                 $sql .= " AND sorder.debtor_no=".db_escape($customer_id);
157
158         $sql .= " GROUP BY sorder.order_no";
159
160         return $sql;
161 }
162 //-------------------------------------------------------------------------------------------------------------
163
164 function get_allocatable_to_cust_transactions($customer_id = null, $trans_no=null, $type=null)
165 {
166         $sql = "SELECT
167                 trans.type,
168                 trans.trans_no,
169                 trans.reference,
170                 trans.tran_date,
171                 debtor.name AS DebtorName, 
172                 debtor.curr_code,
173                 ov_amount+ov_gst+ov_freight+ov_freight_tax+ov_discount AS Total,
174                 trans.alloc,
175                 trans.due_date,
176                 debtor.address,
177                 trans.version,
178                 amt
179          FROM ".TB_PREF."debtor_trans as trans
180                         LEFT JOIN ".TB_PREF."cust_allocations as alloc ON trans.trans_no = alloc.trans_no_to AND trans.type = alloc.trans_type_to,"
181                         .TB_PREF."debtors_master as debtor
182          WHERE
183                  trans.debtor_no=debtor.debtor_no";
184         if ($customer_id)
185                 $sql .= " AND trans.debtor_no=".db_escape($customer_id);
186
187         if ($trans_no != null and $type != null)
188         {
189                 $sql .= " AND alloc.trans_no_from=".db_escape($trans_no)."
190                                   AND alloc.trans_type_from=".db_escape($type);
191         }
192         else
193         {
194                 $sql .= " AND round(IF(prep_amount, prep_amount, ov_amount+ov_gst+ov_freight+ov_freight_tax+ov_discount)-alloc,6) > 0
195                         AND trans.type NOT IN (".implode(',',array(ST_CUSTPAYMENT,ST_BANKDEPOSIT,ST_CUSTCREDIT,ST_CUSTDELIVERY)).")";
196                 $sql .= " GROUP BY type, trans_no";
197         }
198         $orders = get_allocatable_sales_orders($customer_id, $trans_no, $type);
199         $sql = "($sql ORDER BY trans_no) \nUNION \n($orders)";
200
201         return db_query($sql, "Cannot retreive alloc to transactions");
202 }
203
204 //-------------------------------------------------------------------------------------------------------------
205
206 function get_allocatable_from_cust_transactions($customer_id, $trans_no=null, $type=null)
207 {
208
209         $sql = "SELECT
210                 trans.type,
211                 trans.trans_no,
212                 trans.reference,
213                 trans.tran_date,
214                 debtor.name AS DebtorName, 
215                 debtor.curr_code,
216                 ov_amount+ov_gst+ov_freight+ov_freight_tax+ov_discount AS Total,
217                 trans.alloc,
218                 trans.due_date,
219                 debtor.address,
220                 trans.version,
221                 amt
222          FROM  ".TB_PREF."debtor_trans as trans,"
223                         .TB_PREF."debtors_master as debtor,"
224                         .TB_PREF."cust_allocations as alloc
225          WHERE trans.debtor_no=debtor.debtor_no
226                         AND trans.trans_no = alloc.trans_no_from
227                         AND trans.type = alloc.trans_type_from";
228
229         if ($trans_no != null and $type != null)
230         {
231                 $sql .= " AND alloc.trans_no_to=".db_escape($trans_no)."
232                                   AND alloc.trans_type_to=".db_escape($type);
233         }
234         else
235         {
236                 $sql .= " AND round(ov_amount+ov_gst+ov_freight+ov_freight_tax+ov_discount-alloc,6) > 0
237                         AND trans.type NOT IN (".implode(',',array(ST_CUSTPAYMENT,ST_BANKDEPOSIT,ST_CUSTCREDIT,ST_CUSTDELIVERY)).")";
238                 $sql .= " GROUP BY type, trans_no";
239         }
240
241         if($customer_id)
242                 $sql .= " AND trans.debtor_no=".db_escape($customer_id);
243
244         return db_query($sql." ORDER BY trans_no", "Cannot retreive alloc to transactions");
245 }
246
247 function get_sql_for_customer_allocation_inquiry($from, $to, $customer, $filterType, $settled)
248 {
249         $data_after = date2sql($from);
250         $date_to = date2sql($to);
251
252         $sql = "SELECT 
253                 trans.type,
254                 trans.trans_no,
255                 trans.reference,
256                 trans.order_,
257                 trans.tran_date,
258                 trans.due_date,
259                 debtor.name,
260                 debtor.curr_code,
261                 debtor.debtor_no,
262         (trans.ov_amount + trans.ov_gst + trans.ov_freight 
263                         + trans.ov_freight_tax + trans.ov_discount)     AS TotalAmount,
264                 trans.alloc AS Allocated,
265                 ((trans.type = ".ST_SALESINVOICE.")
266                         AND trans.due_date < '" . date2sql(Today()) . "') AS OverDue
267         FROM "
268                         .TB_PREF."debtor_trans as trans, "
269                         .TB_PREF."debtors_master as debtor
270         WHERE debtor.debtor_no = trans.debtor_no
271                         AND (trans.ov_amount + trans.ov_gst + trans.ov_freight 
272                                 + trans.ov_freight_tax + trans.ov_discount != 0)
273                 AND trans.tran_date >= '$data_after'
274                 AND trans.tran_date <= '$date_to'";
275
276         if ($customer != ALL_TEXT)
277                 $sql .= " AND trans.debtor_no = ".db_escape($customer);
278
279         if (isset($filterType) && $filterType != ALL_TEXT)
280         {
281                 if ($filterType == '1' || $filterType == '2')
282                 {
283                         $sql .= " AND trans.type = ".ST_SALESINVOICE." ";
284                 }
285                 elseif ($filterType == '3')
286                 {
287                         $sql .= " AND trans.type = " . ST_CUSTPAYMENT;
288                 }
289                 elseif ($filterType == '4')
290                 {
291                         $sql .= " AND trans.type = ".ST_CUSTCREDIT." ";
292                 }
293
294         if ($filterType == '2')
295         {
296                 $today =  date2sql(Today());
297                 $sql .= " AND trans.due_date < '$today'
298                                 AND (round(abs(trans.ov_amount + "
299                                 ."trans.ov_gst + trans.ov_freight + "
300                                 ."trans.ov_freight_tax + trans.ov_discount) - trans.alloc,6) > 0) ";
301         }
302         }
303         else
304         {
305             $sql .= " AND trans.type <> ".ST_CUSTDELIVERY." ";
306         }
307
308
309         if (!$settled)
310         {
311                 $sql .= " AND (round(IF(trans.prep_amount,trans.prep_amount, abs(trans.ov_amount + trans.ov_gst + "
312                 ."trans.ov_freight + trans.ov_freight_tax + "
313                 ."trans.ov_discount)) - trans.alloc,6) != 0) ";
314         }
315
316         return $sql;
317 }
318
319 function credit_sales_invoice_allocate($invoice_no, $credit_no, $amount, $date)
320 {
321
322         $sql = "SELECT ov_freight+ov_gst+ov_amount+ov_freight_tax as total, alloc FROM ".TB_PREF."debtor_trans
323                 WHERE (`type`=".ST_SALESINVOICE." AND trans_no=".db_escape($invoice_no).")";
324         $result = db_query($sql, "can't retrieve invoice totals");
325         $invoice = db_fetch($result);
326         $free = $invoice['total'] - $invoice['alloc'];
327         
328         if ($free < $amount) {
329          // if there is not enough unallocated amount - remove some payment allocations
330                 $sql = "SELECT * FROM ".TB_PREF."cust_allocations
331                         WHERE (trans_type_to=".ST_SALESINVOICE." AND trans_no_to=".db_escape($invoice_no).")
332                         AND trans_type_from <> ".ST_CUSTCREDIT;
333                 $result = db_query($sql, "can't retrieve invoice allocations");
334
335                 while(($free < $amount) && ($alloc = db_fetch($result))) {
336                         $unalloc = min($alloc['amt'], $amount-$free);
337
338                         delete_cust_allocation($alloc['id']);
339                         if ($unalloc < $alloc['amt'])
340                                 add_cust_allocation($alloc['amt']-$unalloc, $alloc['trans_type_from'],
341                                         $alloc['trans_no_from'], ST_SALESINVOICE, $invoice_no);
342
343                         update_debtor_trans_allocation($alloc['trans_type_to'], $alloc['trans_no_to']);
344                         update_debtor_trans_allocation($alloc['trans_type_from'], $alloc['trans_no_from']);
345                         $free += $unalloc;
346                 }
347         }
348         if (floatcmp($free, $amount)<0) {
349                 // this should never happen unless sparse credit notices were allocated to 
350                 // the invoice, or summarized freight costs on credit notes is more than those on invoice.
351                 display_error(_("Unsuspected overallocation happened due to sparse credit notes exists for this invoice.
352  Check all credit notes allocated to this invoice for summarized freight charges."));
353                 return false;
354         }
355         update_debtor_trans_allocation(ST_SALESINVOICE, $invoice_no);
356         update_debtor_trans_allocation(ST_CUSTCREDIT, $credit_no);
357         add_cust_allocation($amount, ST_CUSTCREDIT, $credit_no, ST_SALESINVOICE, $invoice_no);
358
359         exchange_variation(ST_CUSTCREDIT, $credit_no, ST_SALESINVOICE, $invoice_no, $date,
360                 $amount, PT_CUSTOMER);
361         return true;
362 }
363
364 ?>