Bug 5676: Currency stored in MySQL DOUBLE Type causes strange error. Fixed by explici...
[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 ? $myrow[0] : 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         $dec = user_price_dec();
56         $sql = "UPDATE `".TB_PREF.($trans_type==ST_PURCHORDER ? 'purch_orders' : 'supp_trans')."` trans,
57                         (SELECT person_id, sum(amt) amt from ".TB_PREF."supp_allocations
58                                 WHERE person_id=".db_escape($person_id)." AND ((trans_type_to=".db_escape($trans_type)." AND trans_no_to=".db_escape($trans_no).")
59                                 OR (trans_type_from=".db_escape($trans_type)." AND trans_no_from=".db_escape($trans_no)."))) allocated
60                 SET
61                         trans.alloc=IFNULL(ROUND(allocated.amt, $dec), 0)
62                 WHERE trans.supplier_id=person_id AND " . ($trans_type==ST_PURCHORDER ? 
63                           "trans.order_no=".db_escape($trans_no)
64                         : "trans.type=".db_escape($trans_type)." AND trans.trans_no=".db_escape($trans_no));
65
66         db_query($sql, "The supp transaction record could not be modified for the allocation against it");
67 }
68
69 //-------------------------------------------------------------------------------------------------------------
70
71 function void_supp_allocations($type, $type_no, $date="")
72 {
73         return clear_supp_alloctions($type, $type_no, null, $date);
74 }
75
76 //-------------------------------------------------------------------------------------------------------------
77
78 function clear_supp_alloctions($type, $type_no, $person_id=null, $date="")
79 {
80         $sql = "UPDATE  ".TB_PREF."supp_allocations ca
81                                 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
82                                 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
83                                 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
84                         SET paym.alloc=paym.alloc - ca.amt,
85                                 st.alloc=st.alloc -  ca.amt,
86                                 po.alloc=po.alloc -  ca.amt
87                         WHERE  ((ca.trans_type_from=".db_escape($type)." AND ca.trans_no_from=".db_escape($type_no).")
88                                 OR (ca.trans_type_to=".db_escape($type)." AND ca.trans_no_to=".db_escape($type_no)."))";
89         if ($person_id)
90                 $sql .= " AND ca.person_id=".db_escape($person_id);
91         db_query($sql, "could not clear allocation");
92
93         // remove any allocations for this transaction
94         $sql = "DELETE FROM ".TB_PREF."supp_allocations
95                         WHERE  ((trans_type_from=".db_escape($type)." AND trans_no_from=".db_escape($type_no).")
96                                 OR (trans_type_to=".db_escape($type)." AND trans_no_to=".db_escape($type_no)."))";
97         if ($person_id)
98                 $sql .= " AND person_id=".db_escape($person_id);
99
100         db_query($sql, "could not void supp transactions for type=$type and trans_no=$type_no");
101 }
102 //-------------------------------------------------------------------------------------------------------------
103
104 function get_allocatable_from_supp_sql($supplier_id, $settled)
105 {
106         $sql = "SELECT
107                 trans.type,
108                 trans.trans_no,
109                 IF(trans.supp_reference='',trans.reference,trans.supp_reference) as reference,
110                 trans.tran_date,
111                 supplier.supp_name, 
112                 supplier.curr_code, 
113                 ov_amount+ov_gst+ov_discount AS Total,
114                 trans.alloc,
115                 trans.due_date,
116                 trans.supplier_id,
117                 supplier.address,
118                 round(abs(ov_amount+ov_gst+ov_discount)-alloc,6) <= 0 AS settled
119          FROM "
120                 .TB_PREF."supp_trans as trans, "
121                 .TB_PREF."suppliers as supplier"
122         ." WHERE trans.supplier_id=supplier.supplier_id
123                 AND type IN(".ST_SUPPAYMENT.",".ST_SUPPCREDIT.",".ST_BANKPAYMENT.",".ST_JOURNAL.") AND (trans.ov_amount < 0)";
124
125         if (!$settled)
126                 $sql .= " AND (round(abs(ov_amount+ov_gst+ov_discount)-alloc,6) > 0)";
127
128         if ($supplier_id != null)
129                 $sql .= " AND supplier.supplier_id = ".db_escape($supplier_id);
130
131         return $sql;
132 }
133
134 function get_allocatable_purch_orders($supplier_id = null, $trans_no=null, $type=null)
135 {
136         $due_dates = "SELECT order_no, MIN(delivery_date) as date
137                 FROM ".TB_PREF."purch_order_details det
138                 GROUP BY det.order_no";
139
140         $sql = "SELECT
141                 ".ST_PURCHORDER." as type,
142                 porder.order_no as trans_no,
143                 porder.reference,
144                 porder.ord_date,
145                 supplier.supp_name AS DebtorName, 
146                 supplier.curr_code,
147                 total as Total,
148                 porder.alloc,
149                 due_dates.date as due_date,
150                 supplier.address,
151                 amt,
152                 requisition_no as supp_ref
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
195          FROM ".TB_PREF."supp_trans as trans
196                         LEFT JOIN ".TB_PREF."supp_allocations as alloc
197                                 ON trans.trans_no = alloc.trans_no_to AND trans.type = alloc.trans_type_to AND alloc.person_id=trans.supplier_id,"
198                         .TB_PREF."suppliers as supplier
199          WHERE
200                  trans.supplier_id=supplier.supplier_id";
201         if ($supplier_id)
202                 $sql .= " AND supplier.supplier_id=".db_escape($supplier_id);
203
204         if ($trans_no != null and $type != null)
205         {
206                 $sql .= " AND alloc.trans_no_from=".db_escape($trans_no)."
207                                   AND alloc.trans_type_from=".db_escape($type);
208         }
209         else
210         {
211                 $sql .= " AND round(ov_amount+ov_gst+ov_discount-alloc,6) > 0
212                         AND trans.type NOT IN (".implode(',',array(ST_SUPPAYMENT, ST_BANKPAYMENT)).")";
213                 $sql .= " GROUP BY type, trans_no";
214         }
215
216         $orders = get_allocatable_purch_orders($supplier_id, $trans_no, $type);
217         $sql = "($sql ORDER BY trans_no) \nUNION \n($orders)";
218
219         return db_query($sql." ORDER BY due_date", "Cannot retreive alloc to transactions");
220 }
221
222 //-------------------------------------------------------------------------------------------------------------
223
224 function get_allocatable_from_supp_transactions($supplier_id, $trans_no=null, $type=null)
225 {
226         $sql = "SELECT
227                 trans.type,
228                 trans.trans_no,
229                 IF(trans.supp_reference='',trans.reference,trans.supp_reference) as reference,
230                 trans.tran_date,
231                 supplier.supp_name, 
232                 supplier.curr_code, 
233                 ov_amount+ov_gst+ov_discount AS Total,
234                 trans.alloc,
235                 trans.due_date,
236                 trans.supplier_id,
237                 supplier.address,
238                 amt,
239                 supp_reference
240          FROM  ".TB_PREF."supp_trans as trans,"
241                         .TB_PREF."suppliers as supplier,"
242                         .TB_PREF."supp_allocations as alloc
243          WHERE trans.supplier_id=supplier.supplier_id
244                         AND trans.trans_no = alloc.trans_no_from
245                         AND trans.type = alloc.trans_type_from
246                         AND trans.supplier_id = alloc.person_id";
247
248         if ($trans_no != null and $type != null)
249         {
250                 $sql .= " AND alloc.trans_no_to=".db_escape($trans_no)."
251                                   AND alloc.trans_type_to=".db_escape($type);
252         }
253         else
254         {
255                 $sql .= " AND round(ABS(ov_amount+ov_gst+ov_discount)-alloc,6) > 0
256                         AND trans.type NOT IN (".implode(',',array(ST_SUPPAYMENT,ST_BANKPAYMENT)).")";
257                 $sql .= " GROUP BY type, trans_no";
258         }
259         return db_query($sql." ORDER BY due_date", "Cannot retreive alloc to transactions");
260 }
261
262 function get_sql_for_supplier_allocation_inquiry()
263 {
264         $date_after = date2sql($_POST['TransAfterDate']);
265         $date_to = date2sql($_POST['TransToDate']);
266
267     $sql = "SELECT 
268                 trans.type, 
269                 trans.trans_no,
270                 trans.reference, 
271                 supplier.supp_name, 
272                 trans.supp_reference,
273         trans.tran_date, 
274                 trans.due_date,
275                 supplier.curr_code, 
276         (trans.ov_amount + trans.ov_gst  + trans.ov_discount) AS TotalAmount, 
277                 trans.alloc AS Allocated,
278                 ((trans.type = ".ST_SUPPINVOICE." OR trans.type = ".ST_SUPPCREDIT.") AND trans.due_date < '" . date2sql(Today()) . "') AS OverDue,
279                 trans.supplier_id
280         FROM "
281                         .TB_PREF."supp_trans as trans
282                         LEFT JOIN ".TB_PREF."voided as v
283                                 ON trans.trans_no=v.id AND trans.type=v.type,"
284                         .TB_PREF."suppliers as supplier
285         WHERE supplier.supplier_id = trans.supplier_id
286         AND trans.tran_date >= '$date_after'
287                 AND trans.tran_date <= '$date_to'
288                 AND ISNULL(v.date_)";
289
290         if ($_POST['supplier_id'] != ALL_TEXT)
291                 $sql .= " AND trans.supplier_id = ".db_escape($_POST['supplier_id']);
292         if (isset($_POST['filterType']) && $_POST['filterType'] != ALL_TEXT)
293         {
294                 if (($_POST['filterType'] == '1') || ($_POST['filterType'] == '2')) // invoices
295                 {
296                         $sql .= " AND trans.type = ".ST_SUPPINVOICE." ";
297                 }
298                 elseif ($_POST['filterType'] == '3')    // payments
299                 {
300                         $sql .= " AND trans.type = ".ST_SUPPAYMENT." ";
301                 }
302                 elseif (($_POST['filterType'] == '4') || ($_POST['filterType'] == '5')) // credits
303                 {
304                         $sql .= " AND trans.type = ".ST_SUPPCREDIT." ";
305                 }
306                 elseif ($_POST['filterType'] == '6')    // Journal
307                 {
308                         $sql .= " AND trans.type = ".ST_JOURNAL." ";
309                 }
310
311                 if (($_POST['filterType'] == '2') || ($_POST['filterType'] == '5')) // overdude 
312                 {
313                         $today =  date2sql(Today());
314                         $sql .= " AND trans.due_date < '$today' ";
315                 }
316         }
317
318         if (!check_value('showSettled'))
319         {
320                 $sql .= " AND (round(abs(ov_amount + ov_gst + ov_discount) - alloc,6) != 0) ";
321         }
322         return $sql;
323 }