c8ad5c46adf137c0dbd920b495adf8e7d793f9c7
[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 }
101 //-------------------------------------------------------------------------------------------------------------
102
103 function get_allocatable_from_supp_sql($supplier_id=null, $settled)
104 {
105         $sql = "SELECT
106                 trans.type,
107                 trans.trans_no,
108                 IF(trans.supp_reference='',trans.reference,trans.supp_reference) as reference,
109                 trans.tran_date,
110                 supplier.supp_name, 
111                 supplier.curr_code, 
112                 ov_amount+ov_gst+ov_discount AS Total,
113                 trans.alloc,
114                 trans.due_date,
115                 trans.supplier_id,
116                 supplier.address,
117                 round(abs(ov_amount+ov_gst+ov_discount)-alloc,6) <= 0 AS settled
118          FROM "
119                 .TB_PREF."supp_trans as trans, "
120                 .TB_PREF."suppliers as supplier"
121         ." WHERE trans.supplier_id=supplier.supplier_id
122                 AND type IN(".ST_SUPPAYMENT.",".ST_SUPPCREDIT.",".ST_BANKPAYMENT.",".ST_JOURNAL.") AND (trans.ov_amount < 0)";
123
124         if (!$settled)
125                 $sql .= " AND (round(abs(ov_amount+ov_gst+ov_discount)-alloc,6) > 0)";
126
127         if ($supplier_id != null)
128                 $sql .= " AND supplier.supplier_id = ".db_escape($supplier_id);
129
130         return $sql;
131 }
132
133 function get_allocatable_purch_orders($supplier_id = null, $trans_no=null, $type=null)
134 {
135         $due_dates = "SELECT order_no, MIN(delivery_date) as date
136                 FROM ".TB_PREF."purch_order_details det
137                 GROUP BY det.order_no";
138
139         $sql = "SELECT
140                 ".ST_PURCHORDER." as type,
141                 porder.order_no as trans_no,
142                 porder.reference,
143                 porder.ord_date,
144                 supplier.supp_name AS DebtorName, 
145                 supplier.curr_code,
146                 total as Total,
147                 porder.alloc,
148                 due_dates.date as due_date,
149                 supplier.address,
150                 amt,
151                 supp_reference as supp_ref,
152                 0, 0
153                 FROM ".TB_PREF."purch_orders as porder
154                         LEFT JOIN ".TB_PREF."suppliers as supplier ON porder.supplier_id = supplier.supplier_id
155                         LEFT JOIN ".TB_PREF."supp_allocations as alloc
156                                 ON porder.order_no = alloc.trans_no_to AND alloc.trans_type_to=".ST_PURCHORDER." AND alloc.person_id=porder.supplier_id
157                         LEFT JOIN ".TB_PREF."grn_batch as grn ON porder.order_no = grn.purch_order_no
158                         LEFT JOIN ($due_dates) due_dates ON due_dates.order_no=porder.order_no
159                 WHERE total>0";
160
161         if ($trans_no != null and $type != null)
162         {
163                 $sql .= " AND alloc.trans_no_from=".db_escape($trans_no)."
164                                   AND alloc.trans_type_from=".db_escape($type);
165         }
166         else
167         {
168                 $sql .= " AND ISNULL(grn.purch_order_no)"; // only sales orders no yet received
169         }
170         if ($supplier_id)
171                 $sql .= " AND porder.supplier_id=".db_escape($supplier_id);
172
173         $sql .= " GROUP BY porder.order_no, grn.purch_order_no";
174
175         return $sql;
176 }
177 //-------------------------------------------------------------------------------------------------------------
178
179 function get_allocatable_to_supp_transactions($supplier_id=null, $trans_no=null, $type=null)
180 {
181         $sql = "SELECT
182                 trans.type,
183                 trans.trans_no,
184                 IF(trans.supp_reference='',trans.reference,trans.supp_reference) as reference,
185                 trans.tran_date,
186                 supplier.supp_name, 
187                 supplier.curr_code, 
188                 ov_amount+ov_gst+ov_discount AS Total,
189                 trans.alloc,
190                 trans.due_date,
191                 trans.supplier_id,
192                 amt,
193                 supp_reference,
194                 pmt.early_days,
195                 pmt.early_discount
196
197          FROM ".TB_PREF."supp_trans as trans
198                         LEFT JOIN ".TB_PREF."suppliers supplier ON trans.supplier_id=supplier.supplier_id
199                         LEFT JOIN ".TB_PREF."payment_terms as pmt ON supplier.payment_terms=pmt.id
200                         LEFT JOIN ".TB_PREF."supp_allocations as alloc
201                                 ON trans.trans_no = alloc.trans_no_to AND trans.type = alloc.trans_type_to AND alloc.person_id=trans.supplier_id";
202
203         if ($trans_no != null and $type != null)
204         {
205                 $sql .= " WHERE alloc.trans_no_from=".db_escape($trans_no)."
206                                   AND alloc.trans_type_from=".db_escape($type);
207         }
208         else
209         {
210                 $sql .= " WHERE round(ov_amount+ov_gst+ov_discount-alloc,6) > 0
211                         AND trans.type NOT IN (".implode(',',array(ST_SUPPAYMENT, ST_BANKPAYMENT)).")";
212         }
213
214         if ($supplier_id)
215                 $sql .= " AND supplier.supplier_id=".db_escape($supplier_id);
216
217
218         $orders = get_allocatable_purch_orders($supplier_id, $trans_no, $type);
219         $sql = "($sql ORDER BY trans_no) \nUNION \n($orders)";
220
221         return db_query($sql." ORDER BY due_date", "Cannot retreive alloc to transactions");
222 }
223
224 //-------------------------------------------------------------------------------------------------------------
225
226 function get_allocatable_from_supp_transactions($supplier_id, $trans_no=null, $type=null)
227 {
228         $sql = "SELECT
229                 trans.type,
230                 trans.trans_no,
231                 IF(trans.supp_reference='',trans.reference,trans.supp_reference) as reference,
232                 trans.tran_date,
233                 supplier.supp_name, 
234                 supplier.curr_code, 
235                 ov_amount+ov_gst+ov_discount AS Total,
236                 trans.alloc,
237                 trans.due_date,
238                 trans.supplier_id,
239                 supplier.address,
240                 amt,
241                 supp_reference
242          FROM  ".TB_PREF."supp_trans as trans,"
243                         .TB_PREF."suppliers as supplier,"
244                         .TB_PREF."supp_allocations as alloc
245          WHERE trans.supplier_id=supplier.supplier_id
246                         AND trans.trans_no = alloc.trans_no_from
247                         AND trans.type = alloc.trans_type_from
248                         AND trans.supplier_id = alloc.person_id";
249
250         if ($trans_no != null and $type != null)
251         {
252                 $sql .= " AND alloc.trans_no_to=".db_escape($trans_no)."
253                                   AND alloc.trans_type_to=".db_escape($type);
254         }
255         else
256         {
257                 $sql .= " AND round(ABS(ov_amount+ov_gst+ov_discount)-alloc,6) > 0
258                         AND trans.type NOT IN (".implode(',',array(ST_SUPPAYMENT,ST_BANKPAYMENT)).")";
259                 $sql .= " GROUP BY type, trans_no";
260         }
261         return db_query($sql." ORDER BY due_date", "Cannot retreive alloc to transactions");
262 }
263
264 function get_sql_for_supplier_allocation_inquiry()
265 {
266         $date_after = date2sql($_POST['TransAfterDate']);
267         $date_to = date2sql($_POST['TransToDate']);
268
269     $sql = "SELECT 
270                 trans.type, 
271                 trans.trans_no,
272                 trans.reference, 
273                 supplier.supp_name, 
274                 trans.supp_reference,
275         trans.tran_date, 
276                 trans.due_date,
277                 supplier.curr_code, 
278         (trans.ov_amount + trans.ov_gst  + trans.ov_discount) AS TotalAmount, 
279                 trans.alloc AS Allocated,
280                 ((trans.type = ".ST_SUPPINVOICE." OR trans.type = ".ST_SUPPCREDIT.") AND trans.due_date < '" . date2sql(Today()) . "') AS OverDue,
281                 trans.supplier_id
282         FROM "
283                         .TB_PREF."supp_trans as trans
284                         LEFT JOIN ".TB_PREF."voided as v
285                                 ON trans.trans_no=v.id AND trans.type=v.type,"
286                         .TB_PREF."suppliers as supplier
287         WHERE supplier.supplier_id = trans.supplier_id
288         AND trans.tran_date >= '$date_after'
289                 AND trans.tran_date <= '$date_to'
290                 AND ISNULL(v.date_)";
291
292         if ($_POST['supplier_id'] != ALL_TEXT)
293                 $sql .= " AND trans.supplier_id = ".db_escape($_POST['supplier_id']);
294         if (isset($_POST['filterType']) && $_POST['filterType'] != ALL_TEXT)
295         {
296                 if (($_POST['filterType'] == '1') || ($_POST['filterType'] == '2')) // invoices
297                 {
298                         $sql .= " AND trans.type = ".ST_SUPPINVOICE." ";
299                 }
300                 elseif ($_POST['filterType'] == '3')    // payments
301                 {
302                         $sql .= " AND trans.type = ".ST_SUPPAYMENT." ";
303                 }
304                 elseif (($_POST['filterType'] == '4') || ($_POST['filterType'] == '5')) // credits
305                 {
306                         $sql .= " AND trans.type = ".ST_SUPPCREDIT." ";
307                 }
308
309                 if (($_POST['filterType'] == '2') || ($_POST['filterType'] == '5')) // overdude 
310                 {
311                         $today =  date2sql(Today());
312                         $sql .= " AND trans.due_date < '$today' ";
313                 }
314         }
315
316         if (!check_value('showSettled'))
317         {
318                 $sql .= " AND (round(abs(ov_amount + ov_gst + ov_discount) - alloc,6) != 0) ";
319         }
320         return $sql;
321 }