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