Merged changes from master branch up to current state.
[fa-stable.git] / purchasing / includes / db / suppalloc_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_supp_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."supp_allocations (
19                 amt, date_alloc,
20                 trans_type_from, trans_no_from, trans_no_to, trans_type_to, person_id)
21                 VALUES (".db_escape($amount).", '$date', "
22                 .db_escape($trans_type_from).", ".db_escape($trans_no_from).", "
23                 .db_escape($trans_no_to).", ".db_escape($trans_type_to).", ".db_escape($person_id).")";
24
25         db_query($sql, "A supplier allocation could not be added to the database");
26 }
27
28 //----------------------------------------------------------------------------------------
29
30
31 function delete_supp_allocation($trans_id)
32 {
33         $sql = "DELETE FROM ".TB_PREF."supp_allocations WHERE id = ".db_escape($trans_id);
34         db_query($sql, "The existing allocation $trans_id could not be deleted");
35 }
36
37 //----------------------------------------------------------------------------------------
38
39 function get_supp_trans_allocation_balance($trans_type, $trans_no)
40 {
41         $sql = "SELECT (ov_amount+ov_gst-ov_discount-alloc) AS BalToAllocate
42                 FROM ".TB_PREF."supp_trans WHERE trans_no="
43                 .db_escape($trans_no)." AND type=".db_escape($trans_type);
44         $result = db_query($sql,"calculate the allocation");
45         $myrow = db_fetch_row($result);
46
47         return $myrow[0];
48 }
49
50 //----------------------------------------------------------------------------------------
51 //      Update supplier trans alloc field according to current status of supp_allocations
52 //
53 function update_supp_trans_allocation($trans_type, $trans_no, $person_id)
54 {
55         $sql = "UPDATE `".TB_PREF.($trans_type==ST_PURCHORDER ? 'purch_orders' : 'supp_trans')."` trans,
56                         (SELECT person_id, sum(amt) amt from ".TB_PREF."supp_allocations
57                                 WHERE person_id=".db_escape($person_id)." AND ((trans_type_to=".db_escape($trans_type)." AND trans_no_to=".db_escape($trans_no).")
58                                 OR (trans_type_from=".db_escape($trans_type)." AND trans_no_from=".db_escape($trans_no)."))) allocated
59                 SET
60                         trans.alloc=IFNULL(allocated.amt, 0)
61                 WHERE trans.supplier_id=person_id AND " . ($trans_type==ST_PURCHORDER ? 
62                           "trans.order_no=".db_escape($trans_no)
63                         : "trans.type=".db_escape($trans_type)." AND trans.trans_no=".db_escape($trans_no));
64
65         db_query($sql, "The supp transaction record could not be modified for the allocation against it");
66 }
67
68 //-------------------------------------------------------------------------------------------------------------
69
70 function void_supp_allocations($type, $type_no, $date="")
71 {
72         return clear_supp_alloctions($type, $type_no, null, $date);
73 }
74
75 //-------------------------------------------------------------------------------------------------------------
76
77 function clear_supp_alloctions($type, $type_no, $person_id=null, $date="")
78 {
79         $sql = "UPDATE  ".TB_PREF."supp_allocations ca
80                                 LEFT JOIN ".TB_PREF."supp_trans paym ON ca.trans_type_from=paym.type AND ca.trans_no_from=paym.trans_no AND ca.person_id=paym.supplier_id
81                                 LEFT JOIN ".TB_PREF."supp_trans st ON ca.trans_type_to=st.type AND ca.trans_no_to=st.trans_no AND ca.person_id=st.supplier_id
82                                 LEFT JOIN ".TB_PREF."purch_orders po ON ca.trans_type_to=".ST_PURCHORDER." AND ca.trans_no_to=po.order_no AND ca.person_id=po.supplier_id
83                         SET paym.alloc=paym.alloc - ca.amt,
84                                 st.alloc=st.alloc -  ca.amt,
85                                 po.alloc=po.alloc -  ca.amt
86                         WHERE  ((ca.trans_type_from=".db_escape($type)." AND ca.trans_no_from=".db_escape($type_no).")
87                                 OR (ca.trans_type_to=".db_escape($type)." AND ca.trans_no_to=".db_escape($type_no)."))";
88         if ($person_id)
89                 $sql .= " AND ca.person_id=".db_escape($person_id);
90         db_query($sql, "could not clear allocation");
91
92         // remove any allocations for this transaction
93         $sql = "DELETE FROM ".TB_PREF."supp_allocations
94                         WHERE  ((trans_type_from=".db_escape($type)." AND trans_no_from=".db_escape($type_no).")
95                                 OR (trans_type_to=".db_escape($type)." AND trans_no_to=".db_escape($type_no)."))";
96         if ($person_id)
97                 $sql .= " AND person_id=".db_escape($person_id);
98
99         db_query($sql, "could not void supp transactions for type=$type and trans_no=$type_no");
100 // is this necessary?
101 //      if ($date != "")
102 //              exchange_variation($type, $type_no, $row['trans_type_to'], $row['trans_no_to'], $date,
103 //                      $row['amt'], PT_SUPPLIER, true);
104 }
105 //-------------------------------------------------------------------------------------------------------------
106
107 function get_allocatable_from_supp_sql($supplier_id=null, $settled)
108 {
109         $sql = "SELECT
110                 trans.type,
111                 trans.trans_no,
112                 IF(trans.supp_reference='',trans.reference,trans.supp_reference) as reference,
113                 trans.tran_date,
114                 supplier.supp_name, 
115                 supplier.curr_code, 
116                 ov_amount+ov_gst+ov_discount AS Total,
117                 trans.alloc,
118                 trans.due_date,
119                 trans.supplier_id,
120                 supplier.address,
121                 round(abs(ov_amount+ov_gst+ov_discount)-alloc,6) <= 0 AS settled
122          FROM "
123                 .TB_PREF."supp_trans as trans, "
124                 .TB_PREF."suppliers as supplier"
125         ." WHERE trans.supplier_id=supplier.supplier_id
126                 AND type IN(".ST_SUPPAYMENT.",".ST_SUPPCREDIT.",".ST_BANKPAYMENT.",".ST_JOURNAL.") AND (trans.ov_amount < 0)";
127
128         if (!$settled)
129                 $sql .= " AND (round(abs(ov_amount+ov_gst+ov_discount)-alloc,6) > 0)";
130
131         if ($supplier_id != null)
132                 $sql .= " AND supplier.supplier_id = ".db_escape($supplier_id);
133
134         return $sql;
135 }
136
137 function get_allocatable_purch_orders($supplier_id = null, $trans_no=null, $type=null)
138 {
139         $due_dates = "SELECT order_no, MIN(delivery_date) as date
140                 FROM ".TB_PREF."purch_order_details det
141                 GROUP BY det.order_no";
142
143         $sql = "SELECT
144                 ".ST_PURCHORDER." as type,
145                 porder.order_no as trans_no,
146                 porder.reference,
147                 porder.ord_date,
148                 supplier.supp_name AS DebtorName, 
149                 supplier.curr_code,
150                 total as Total,
151                 porder.alloc,
152                 due_dates.date as due_date,
153                 supplier.address,
154                 amt,
155                 requisition_no as supp_ref
156                 FROM ".TB_PREF."purch_orders as porder
157                         LEFT JOIN ".TB_PREF."suppliers as supplier ON porder.supplier_id = supplier.supplier_id
158                         LEFT JOIN ".TB_PREF."supp_allocations as alloc
159                                 ON porder.order_no = alloc.trans_no_to AND alloc.trans_type_to=".ST_PURCHORDER." AND alloc.person_id=porder.supplier_id
160                         LEFT JOIN ".TB_PREF."grn_batch as grn ON porder.order_no = grn.purch_order_no
161                         LEFT JOIN ($due_dates) due_dates ON due_dates.order_no=porder.order_no
162                 WHERE total>0";
163
164         if ($trans_no != null and $type != null)
165         {
166                 $sql .= " AND alloc.trans_no_from=".db_escape($trans_no)."
167                                   AND alloc.trans_type_from=".db_escape($type);
168         }
169         else
170         {
171 //      FIXME: change to form below when prepayments terms finally can be selected in PO entry form:
172 //              $sql .= " AND round(prep_amount) > 0 AND ISNULL(grn.purch_order_no)"; // only sales orders with prepayment level set and no yet received
173                 $sql .= " AND ISNULL(grn.purch_order_no)"; // only sales orders no yet received
174         }
175         if ($supplier_id)
176                 $sql .= " AND porder.supplier_id=".db_escape($supplier_id);
177
178         $sql .= " GROUP BY porder.order_no, grn.purch_order_no";
179
180         return $sql;
181 }
182 //-------------------------------------------------------------------------------------------------------------
183
184 function get_allocatable_to_supp_transactions($supplier_id=null, $trans_no=null, $type=null)
185 {
186         $sql = "SELECT
187                 trans.type,
188                 trans.trans_no,
189                 IF(trans.supp_reference='',trans.reference,trans.supp_reference) as reference,
190                 trans.tran_date,
191                 supplier.supp_name, 
192                 supplier.curr_code, 
193                 ov_amount+ov_gst+ov_discount AS Total,
194                 trans.alloc,
195                 trans.due_date,
196                 trans.supplier_id,
197                 amt,
198                 supp_reference
199
200          FROM ".TB_PREF."supp_trans as trans
201                         LEFT JOIN ".TB_PREF."supp_allocations as alloc
202                                 ON trans.trans_no = alloc.trans_no_to AND trans.type = alloc.trans_type_to AND alloc.person_id=trans.supplier_id,"
203                         .TB_PREF."suppliers as supplier
204          WHERE
205                  trans.supplier_id=supplier.supplier_id";
206         if ($supplier_id)
207                 $sql .= " AND supplier.supplier_id=".db_escape($supplier_id);
208
209         if ($trans_no != null and $type != null)
210         {
211                 $sql .= " AND alloc.trans_no_from=".db_escape($trans_no)."
212                                   AND alloc.trans_type_from=".db_escape($type);
213         }
214         else
215         {
216                 $sql .= " AND round(ov_amount+ov_gst+ov_discount-alloc,6) > 0
217                         AND trans.type NOT IN (".implode(',',array(ST_SUPPAYMENT, ST_BANKPAYMENT)).")";
218                 $sql .= " GROUP BY type, trans_no";
219         }
220
221         $orders = get_allocatable_purch_orders($supplier_id, $trans_no, $type);
222         $sql = "($sql ORDER BY trans_no) \nUNION \n($orders)";
223
224         return db_query($sql." ORDER BY due_date", "Cannot retreive alloc to transactions");
225 }
226
227 //-------------------------------------------------------------------------------------------------------------
228
229 function get_allocatable_from_supp_transactions($supplier_id, $trans_no=null, $type=null)
230 {
231         $sql = "SELECT
232                 trans.type,
233                 trans.trans_no,
234                 IF(trans.supp_reference='',trans.reference,trans.supp_reference) as reference,
235                 trans.tran_date,
236                 supplier.supp_name, 
237                 supplier.curr_code, 
238                 ov_amount+ov_gst+ov_discount AS Total,
239                 trans.alloc,
240                 trans.due_date,
241                 trans.supplier_id,
242                 supplier.address,
243                 amt,
244                 supp_reference
245          FROM  ".TB_PREF."supp_trans as trans,"
246                         .TB_PREF."suppliers as supplier,"
247                         .TB_PREF."supp_allocations as alloc
248          WHERE trans.supplier_id=supplier.supplier_id
249                         AND trans.trans_no = alloc.trans_no_from
250                         AND trans.type = alloc.trans_type_from
251                         AND trans.supplier_id = alloc.person_id";
252
253         if ($trans_no != null and $type != null)
254         {
255                 $sql .= " AND alloc.trans_no_to=".db_escape($trans_no)."
256                                   AND alloc.trans_type_to=".db_escape($type);
257         }
258         else
259         {
260                 $sql .= " AND round(ABS(ov_amount+ov_gst+ov_discount)-alloc,6) > 0
261                         AND trans.type NOT IN (".implode(',',array(ST_SUPPAYMENT,ST_BANKPAYMENT)).")";
262                 $sql .= " GROUP BY type, trans_no";
263         }
264 //_vd($sql);
265         return db_query($sql." ORDER BY due_date", "Cannot retreive alloc to transactions");
266 }
267
268 function get_sql_for_supplier_allocation_inquiry()
269 {
270         $date_after = date2sql($_POST['TransAfterDate']);
271         $date_to = date2sql($_POST['TransToDate']);
272
273     $sql = "SELECT 
274                 trans.type, 
275                 trans.trans_no,
276                 trans.reference, 
277                 supplier.supp_name, 
278                 trans.supp_reference,
279         trans.tran_date, 
280                 trans.due_date,
281                 supplier.curr_code, 
282         (trans.ov_amount + trans.ov_gst  + trans.ov_discount) AS TotalAmount, 
283                 trans.alloc AS Allocated,
284                 ((trans.type = ".ST_SUPPINVOICE." OR trans.type = ".ST_SUPPCREDIT.") AND trans.due_date < '" . date2sql(Today()) . "') AS OverDue,
285                 trans.supplier_id
286         FROM "
287                         .TB_PREF."supp_trans as trans
288                         LEFT JOIN ".TB_PREF."voided as v
289                                 ON trans.trans_no=v.id AND trans.type=v.type,"
290                         .TB_PREF."suppliers as supplier
291         WHERE supplier.supplier_id = trans.supplier_id
292         AND trans.tran_date >= '$date_after'
293                 AND trans.tran_date <= '$date_to'
294                 AND ISNULL(v.date_)";
295
296         if ($_POST['supplier_id'] != ALL_TEXT)
297                 $sql .= " AND trans.supplier_id = ".db_escape($_POST['supplier_id']);
298         if (isset($_POST['filterType']) && $_POST['filterType'] != ALL_TEXT)
299         {
300                 if (($_POST['filterType'] == '1') || ($_POST['filterType'] == '2')) // invoices
301                 {
302                         $sql .= " AND trans.type = ".ST_SUPPINVOICE." ";
303                 }
304                 elseif ($_POST['filterType'] == '3')    // payments
305                 {
306                         $sql .= " AND trans.type = ".ST_SUPPAYMENT." ";
307                 }
308                 elseif (($_POST['filterType'] == '4') || ($_POST['filterType'] == '5')) // credits
309                 {
310                         $sql .= " AND trans.type = ".ST_SUPPCREDIT." ";
311                 }
312
313                 if (($_POST['filterType'] == '2') || ($_POST['filterType'] == '5')) // overdude 
314                 {
315                         $today =  date2sql(Today());
316                         $sql .= " AND trans.due_date < '$today' ";
317                 }
318         }
319
320         if (!check_value('showSettled'))
321         {
322                 $sql .= " AND (round(abs(ov_amount + ov_gst + ov_discount) - alloc,6) != 0) ";
323         }
324         return $sql;
325 }