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