Additional fixes for journal handling. Added reg_type in trans_tax_details.
[fa-stable.git] / gl / includes / db / gl_db_trans.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 // Base function for adding a GL transaction
15 // $date_ is display date (non-sql)
16 // $amount is in $currency currency
17 // if $currency is not set, then defaults to no conversion
18
19 function add_gl_trans($type, $trans_id, $date_, $account, $dimension, $dimension2, $memo_,
20         $amount, $currency=null, $person_type_id=null, $person_id=null, $err_msg="", $rate=0)
21 {
22         global $SysPrefs;
23
24         $date = date2sql($date_);
25         if ($currency != null)
26         {
27                 if ($rate == 0)
28                         $amount_in_home_currency = to_home_currency($amount, $currency, $date_);
29                 else
30                         $amount_in_home_currency = round2($amount * $rate,  user_price_dec());
31         }               
32         else
33                 $amount_in_home_currency = round2($amount, user_price_dec());
34         if ($dimension == null || $dimension < 0)
35                 $dimension = 0;
36         if ($dimension2 == null || $dimension2 < 0)
37                 $dimension2 = 0;
38         if (isset($SysPrefs->use_audit_trail) && $SysPrefs->use_audit_trail)
39         {
40                 if ($memo_ == "" || $memo_ == null)
41                         $memo_ = $_SESSION["wa_current_user"]->username;
42                 else
43                         $memo_ = $_SESSION["wa_current_user"]->username . " - " . $memo_;
44         }
45         if (!is_subledger_account($account) || $account==get_company_pref('grn_clearing_act'))
46                 $person_id = $person_type_id = null;
47
48         $sql = "INSERT INTO ".TB_PREF."gl_trans ( type, type_no, tran_date,
49                 account, dimension_id, dimension2_id, memo_, amount";
50
51         if ($person_type_id != null)
52                 $sql .= ", person_type_id, person_id";
53
54         $sql .= ") ";
55
56         $sql .= "VALUES (".db_escape($type).", ".db_escape($trans_id).", '$date',
57                 ".db_escape($account).", ".db_escape($dimension).", "
58                 .db_escape($dimension2).", ".db_escape($memo_).", "
59                 .db_escape($amount_in_home_currency);
60
61         if ($person_type_id != null)
62                 $sql .= ", ".db_escape($person_type_id).", ". db_escape($person_id);
63
64         $sql .= ") ";
65
66         if ($err_msg == "")
67                 $err_msg = "The GL transaction could not be inserted";
68
69         db_query($sql, $err_msg);
70         return $amount_in_home_currency;
71 }
72
73 //--------------------------------------------------------------------------------
74
75 // GL Trans for standard costing, always home currency regardless of person
76 // $date_ is display date (non-sql)
77 // $amount is in HOME currency
78
79 function add_gl_trans_std_cost($type, $trans_id, $date_, $account, $dimension, $dimension2,
80         $memo_, $amount, $person_type_id=null, $person_id=null, $err_msg="")
81 {
82         if ($amount != 0)
83                 return add_gl_trans($type, $trans_id, $date_, $account, $dimension, $dimension2, $memo_,
84                         $amount, null, $person_type_id, $person_id, $err_msg);
85         else
86                 return 0;
87 }
88
89 // Function for even out rounding problems
90 function add_gl_balance($type, $trans_id, $date_, $amount, $person_type_id=null, $person_id=null)
91 {
92         $amount = round2($amount, user_price_dec());
93
94         if (floatcmp($amount, 0))
95         {
96                 error_log(sprintf( _("Rounding error %s encountered for trans_type:%s,trans_no:%s"), $amount, $type, $trans_id));
97                 return add_gl_trans($type, $trans_id, $date_, get_company_pref('exchange_diff_act'), 0, 0, "",
98                         $amount, null, $person_type_id, $person_id, "The balanced GL transaction could not be inserted");
99         } else
100                 return 0;
101 }
102
103 //--------------------------------------------------------------------------------
104
105 function get_gl_transactions($from_date, $to_date, $trans_no=0,
106         $account=null, $dimension=0, $dimension2=0, $filter_type=null,
107         $amount_min=null, $amount_max=null, $person_id=null)
108 {
109         global $SysPrefs;
110
111         $from = date2sql($from_date);
112         $to = date2sql($to_date);
113
114         $sql = "SELECT gl.*, j.event_date, j.doc_date, a.gl_seq, u.user_id, st.supp_reference, gl.person_id subcode,
115                         IFNULL(IFNULL(sup.supp_name, debt.name), bt.person_id) as person_name, 
116                         IFNULL(gl.person_id, IFNULL(sup.supplier_id, debt.debtor_no)) as person_id,
117                         IFNULL(st.tran_date, IFNULL(dt.tran_date, IFNULL(bt.trans_date, IFNULL(grn.delivery_date, gl.tran_date)))) as doc_date,
118                         coa.account_name, ref.reference
119                          FROM "
120                         .TB_PREF."gl_trans gl
121                         LEFT JOIN ".TB_PREF."voided v ON gl.type_no=v.id AND v.type=gl.type
122
123                         LEFT JOIN ".TB_PREF."supp_trans st ON gl.type_no=st.trans_no AND st.type=gl.type AND (gl.type!=".ST_JOURNAL." OR gl.person_id=st.supplier_id)
124                         LEFT JOIN ".TB_PREF."grn_batch grn ON grn.id=gl.type_no AND gl.type=".ST_SUPPRECEIVE." AND gl.person_id=grn.supplier_id
125                         LEFT JOIN ".TB_PREF."debtor_trans dt ON gl.type_no=dt.trans_no AND dt.type=gl.type AND (gl.type!=".ST_JOURNAL." OR gl.person_id=dt.debtor_no)
126
127                         LEFT JOIN ".TB_PREF."suppliers sup ON st.supplier_id=sup.supplier_id OR grn.supplier_id=sup.supplier_id
128                         LEFT JOIN ".TB_PREF."cust_branch branch ON dt.branch_code=branch.branch_code
129                         LEFT JOIN ".TB_PREF."debtors_master debt ON dt.debtor_no=debt.debtor_no
130
131                         LEFT JOIN ".TB_PREF."bank_trans bt ON bt.type=gl.type AND bt.trans_no=gl.type_no AND bt.amount!=0
132                                  AND bt.person_type_id=gl.person_type_id AND bt.person_id=gl.person_id
133
134                         LEFT JOIN ".TB_PREF."journal j ON j.type=gl.type AND j.trans_no=gl.type_no
135                         LEFT JOIN ".TB_PREF."audit_trail a ON a.type=gl.type AND a.trans_no=gl.type_no AND NOT ISNULL(gl_seq)
136                         LEFT JOIN ".TB_PREF."users u ON a.user=u.id
137
138                         LEFT JOIN ".TB_PREF."refs ref ON ref.type=gl.type AND ref.id=gl.type_no,"
139                 .TB_PREF."chart_master coa
140                 WHERE coa.account_code=gl.account
141                 AND ISNULL(v.date_)
142                 AND gl.tran_date >= '$from'
143                 AND gl.tran_date <= '$to'";
144         if (isset($SysPrefs->show_voided_gl_trans) && $SysPrefs->show_voided_gl_trans == 0)
145                 $sql .= " AND gl.amount <> 0"; 
146
147         if ($person_id)
148                 $sql .= " AND gl.person_id=".db_escape($person_id); 
149
150         if ($trans_no > 0)
151                 $sql .= " AND gl.type_no LIKE ".db_escape('%'.$trans_no);;
152
153         if ($account != null)
154                 $sql .= " AND gl.account = ".db_escape($account);
155
156         if ($dimension > 0)
157                 $sql .= " AND gl.dimension_id = ".($dimension<0 ? 0 : db_escape($dimension));
158
159         if ($dimension2 > 0)
160                 $sql .= " AND gl.dimension2_id = ".($dimension2<0 ? 0 : db_escape($dimension2));
161
162         if ($filter_type != null AND is_numeric($filter_type))
163                 $sql .= " AND gl.type= ".db_escape($filter_type);
164
165         if ($amount_min != null)
166                 $sql .= " AND ABS(gl.amount) >= ABS(".db_escape($amount_min).")";
167         
168         if ($amount_max != null)
169                 $sql .= " AND ABS(gl.amount) <= ABS(".db_escape($amount_max).")";
170
171         $sql .= " ORDER BY tran_date, counter";
172
173         return db_query($sql, "The transactions for could not be retrieved");
174 }
175
176
177 //--------------------------------------------------------------------------------
178
179 function get_gl_trans($type, $trans_id)
180 {
181         $sql = "SELECT gl.*, cm.account_name, IF(ISNULL(refs.reference), '', refs.reference) AS reference, user.real_name, 
182                         IFNULL(st.tran_date, IFNULL(dt.tran_date, IFNULL(bt.trans_date, IFNULL(grn.delivery_date, gl.tran_date)))) as doc_date,
183                         IF(ISNULL(st.supp_reference), '', st.supp_reference) AS supp_reference
184         FROM ".TB_PREF."gl_trans as gl
185                 LEFT JOIN ".TB_PREF."chart_master as cm ON gl.account = cm.account_code
186                 LEFT JOIN ".TB_PREF."refs as refs ON (gl.type=refs.type AND gl.type_no=refs.id)
187                 LEFT JOIN ".TB_PREF."audit_trail as audit ON (gl.type=audit.type AND gl.type_no=audit.trans_no AND NOT ISNULL(gl_seq))
188                 LEFT JOIN ".TB_PREF."users as user ON (audit.user=user.id)
189         # all this below just to retrieve doc_date :>
190                 LEFT JOIN ".TB_PREF."supp_trans st ON gl.type_no=st.trans_no AND st.type=gl.type AND (gl.type!=".ST_JOURNAL." OR gl.person_id=st.supplier_id)
191                 LEFT JOIN ".TB_PREF."grn_batch grn ON grn.id=gl.type_no AND gl.type=".ST_SUPPRECEIVE." AND gl.person_id=grn.supplier_id
192                 LEFT JOIN ".TB_PREF."debtor_trans dt ON gl.type_no=dt.trans_no AND dt.type=gl.type AND (gl.type!=".ST_JOURNAL." OR gl.person_id=dt.debtor_no)
193                 LEFT JOIN ".TB_PREF."bank_trans bt ON bt.type=gl.type AND bt.trans_no=gl.type_no AND bt.amount!=0
194                          AND bt.person_type_id=gl.person_type_id AND bt.person_id=gl.person_id
195                 LEFT JOIN ".TB_PREF."journal j ON j.type=gl.type AND j.trans_no=gl.type_no"
196
197                 ." WHERE gl.type= ".db_escape($type) 
198                 ." AND gl.type_no = ".db_escape($trans_id)
199                 ." AND gl.amount <> 0"
200                 ." ORDER BY tran_date, counter";
201
202         return db_query($sql, "The gl transactions could not be retrieved");
203 }
204
205 //--------------------------------------------------------------------------------
206
207 function get_gl_wo_cost_trans($trans_id, $cost_type=-1)
208 {
209         $sql = "SELECT costing.*, gl.*, chart.account_name, com.memo_ FROM "
210                 .TB_PREF."wo_costing costing, "
211                 .TB_PREF."gl_trans gl LEFT JOIN ".TB_PREF."comments com ON gl.type=com.type     AND gl.type_no=com.id,"
212                 .TB_PREF."chart_master chart
213                 WHERE 
214                         costing.workorder_id=".db_escape($trans_id)
215                 ."      AND chart.account_code=gl.account
216                         AND gl.type=costing.trans_type
217                         AND gl.type_no=costing.trans_no";
218         if ($cost_type != -1)
219                 $sql .= " AND costing.cost_type=".db_escape($cost_type);
220         $sql .= " AND amount < 0";
221
222         return db_query($sql, "The gl transactions could not be retrieved");
223 }
224
225 function get_gl_balance_from_to($from_date, $to_date, $account, $dimension=0, $dimension2=0)
226 {
227         $from = date2sql($from_date);
228         $to = date2sql($to_date);
229
230     $sql = "SELECT SUM(amount) FROM ".TB_PREF."gl_trans
231                 WHERE account='$account'";
232         if ($from_date != "")
233                 $sql .= "  AND tran_date > '$from'";
234         if ($to_date != "")
235                 $sql .= "  AND tran_date < '$to'";
236         if ($dimension != 0)
237                 $sql .= " AND dimension_id = ".($dimension<0?0:db_escape($dimension));
238         if ($dimension2 != 0)
239                 $sql .= " AND dimension2_id = ".($dimension2<0?0:db_escape($dimension2));
240
241         $result = db_query($sql, "The starting balance for account $account could not be calculated");
242
243         $row = db_fetch_row($result);
244         return $row[0];
245 }
246
247 //--------------------------------------------------------------------------------
248
249 function get_gl_trans_from_to($from_date, $to_date, $account, $dimension=0, $dimension2=0)
250 {
251         $from = date2sql($from_date);
252         $to = date2sql($to_date);
253
254     $sql = "SELECT SUM(amount) FROM ".TB_PREF."gl_trans
255                 WHERE account='$account'";
256         if ($from_date != "")
257                 $sql .= " AND tran_date >= '$from'";
258         if ($to_date != "")
259                 $sql .= " AND tran_date <= '$to'";
260         if ($dimension != 0)
261                 $sql .= " AND dimension_id = ".($dimension<0?0:db_escape($dimension));
262         if ($dimension2 != 0)
263                 $sql .= " AND dimension2_id = ".($dimension2<0?0:db_escape($dimension2));
264
265         $result = db_query($sql, "Transactions for account $account could not be calculated");
266
267         $row = db_fetch_row($result);
268         return (float)$row[0];
269 }
270
271 //----------------------------------------------------------------------------------------------------
272 function get_balance($account, $dimension, $dimension2, $from, $to, $from_incl=true, $to_incl=true) 
273 {
274         $sql = "SELECT SUM(IF(amount >= 0, amount, 0)) as debit, 
275                 SUM(IF(amount < 0, -amount, 0)) as credit, SUM(amount) as balance 
276                 FROM ".TB_PREF."gl_trans,".TB_PREF."chart_master,"
277                         .TB_PREF."chart_types, ".TB_PREF."chart_class 
278                 WHERE ".TB_PREF."gl_trans.account=".TB_PREF."chart_master.account_code AND "
279                 .TB_PREF."chart_master.account_type=".TB_PREF."chart_types.id 
280                 AND ".TB_PREF."chart_types.class_id=".TB_PREF."chart_class.cid AND";
281                 
282         if ($account != null)
283                 $sql .= " account=".db_escape($account)." AND";
284         if ($dimension != 0)
285                 $sql .= " dimension_id = ".($dimension<0?0:db_escape($dimension))." AND";
286         if ($dimension2 != 0)
287                 $sql .= " dimension2_id = ".($dimension2<0?0:db_escape($dimension2))." AND";
288         $from_date = date2sql($from);
289         if ($from_incl)
290                 $sql .= " tran_date >= '$from_date'  AND";
291         else
292                 $sql .= " tran_date > IF(ctype>0 AND ctype<".CL_INCOME.", '0000-00-00', '$from_date') AND";
293         $to_date = date2sql($to);
294         if ($to_incl)
295                 $sql .= " tran_date <= '$to_date' ";
296         else
297                 $sql .= " tran_date < '$to_date' ";
298
299         $result = db_query($sql,"No general ledger accounts were returned");
300
301         return db_fetch($result);
302 }
303
304 //--------------------------------------------------------------------------------
305
306 function get_budget_trans_from_to($from_date, $to_date, $account, $dimension=0, $dimension2=0)
307 {
308
309         $from = date2sql($from_date);
310         $to = date2sql($to_date);
311
312         $sql = "SELECT SUM(amount) FROM ".TB_PREF."budget_trans
313                 WHERE account=".db_escape($account);
314         if ($from_date != "")
315                 $sql .= " AND tran_date >= '$from' ";
316         if ($to_date != "")
317                 $sql .= " AND tran_date <= '$to' ";
318         if ($dimension != 0)
319                 $sql .= " AND dimension_id = ".($dimension<0?0:db_escape($dimension));
320         if ($dimension2 != 0)
321                 $sql .= " AND dimension2_id = ".($dimension2<0?0:db_escape($dimension2));
322         $result = db_query($sql,"No budget accounts were returned");
323
324         $row = db_fetch_row($result);
325         return $row[0];
326 }
327 //-------------------------------------------------------------------------------------
328
329 function exists_gl_budget($date_, $account, $dimension, $dimension2)
330 {
331         $sql = "SELECT account FROM ".TB_PREF."budget_trans WHERE account=".db_escape($account)
332         ." AND tran_date='$date_' AND
333                 dimension_id=".db_escape($dimension)." AND dimension2_id=".db_escape($dimension2);
334         $result = db_query($sql, "Cannot retreive a gl transaction");
335
336     return (db_num_rows($result) > 0);
337 }
338
339 function add_update_gl_budget_trans($date_, $account, $dimension, $dimension2, $amount)
340 {
341         $date = date2sql($date_);
342
343         if (exists_gl_budget($date, $account, $dimension, $dimension2))
344                 $sql = "UPDATE ".TB_PREF."budget_trans SET amount=".db_escape($amount)
345                 ." WHERE account=".db_escape($account)
346                 ." AND dimension_id=".db_escape($dimension)
347                 ." AND dimension2_id=".db_escape($dimension2)
348                 ." AND tran_date='$date'";
349         else
350                 $sql = "INSERT INTO ".TB_PREF."budget_trans (tran_date,
351                         account, dimension_id, dimension2_id, amount, memo_) VALUES ('$date',
352                         ".db_escape($account).", ".db_escape($dimension).", "
353                         .db_escape($dimension2).", ".db_escape($amount).", '')";
354
355         db_query($sql, "The GL budget transaction could not be saved");
356 }
357
358 function delete_gl_budget_trans($date_, $account, $dimension, $dimension2)
359 {
360         $date = date2sql($date_);
361
362         $sql = "DELETE FROM ".TB_PREF."budget_trans WHERE account=".db_escape($account)
363         ." AND dimension_id=".db_escape($dimension)
364         ." AND dimension2_id=".db_escape($dimension2)
365         ." AND tran_date='$date'";
366         db_query($sql, "The GL budget transaction could not be deleted");
367 }
368
369 function get_only_budget_trans_from_to($from_date, $to_date, $account, $dimension=0, $dimension2=0)
370 {
371
372         $from = date2sql($from_date);
373         $to = date2sql($to_date);
374
375         $sql = "SELECT SUM(amount) FROM ".TB_PREF."budget_trans
376                 WHERE account=".db_escape($account)
377                 ." AND tran_date >= '$from' AND tran_date <= '$to'
378                  AND dimension_id = ".db_escape($dimension)
379                  ." AND dimension2_id = ".db_escape($dimension2);
380         $result = db_query($sql,"No budget accounts were returned");
381
382         $row = db_fetch_row($result);
383         return $row[0];
384 }
385
386 //--------------------------------------------------------------------------------
387 //      Stores journal/bank transaction tax details if applicable
388 //
389 function add_gl_tax_details($gl_code, $trans_type, $trans_no, $amount, $ex_rate, $date, $memo, $included=0, $net_amount = null)
390 {
391         $tax_type = is_tax_account($gl_code);
392         if(!$tax_type) return;  // $gl_code is not tax account
393         
394         $tax = get_tax_type($tax_type);
395         //if ($gl_code == $tax['sales_gl_code'])
396         if ($trans_type == ST_SALESINVOICE || $trans_type == ST_CUSTDELIVERY || $trans_type == ST_CUSTCREDIT)
397                 $amount = -$amount;
398         // we have to restore net amount as we cannot know the base amount
399         if ($net_amount===null) {
400                 if ($tax['rate'] == 0) {
401 //                      display_warning(_("You should not post gl transactions  
402 //                              to tax account with     zero tax rate."));
403                         $net_amount = 0;
404                 } else { 
405                         // calculate net amount
406                         $net_amount = $amount/$tax['rate']*100; 
407                 }
408         }
409         add_trans_tax_details($trans_type, $trans_no, $tax['id'], $tax['rate'], $included, 
410                 $amount, $net_amount, $ex_rate, $date, $memo, null);
411
412 }
413
414 //--------------------------------------------------------------------------------
415 //
416 //      Store transaction tax details for fiscal purposes with 'freezed' 
417 //      actual tax type rate.
418 //
419 function add_trans_tax_details($trans_type, $trans_no, $tax_id, $rate, $included,
420         $amount, $net_amount, $ex_rate, $tran_date, $memo, $reg_type=null)
421 {
422         // guess tax register if not set
423         if (!isset($reg_type))
424                 $reg_type = in_array($trans_type, array(ST_SUPPINVOICE, ST_SUPPCREDIT)) ? TR_OUTPUT
425                                 : in_array($trans_type, array(ST_SALESINVOICE, ST_CUSTCREDIT)) ? TR_INPUT : null;
426
427         $sql = "INSERT INTO ".TB_PREF."trans_tax_details 
428                 (trans_type, trans_no, tran_date, tax_type_id, rate, ex_rate,
429                         included_in_price, net_amount, amount, memo, reg_type)
430                 VALUES (".db_escape($trans_type)."," . db_escape($trans_no).",'"
431                                 .date2sql($tran_date)."',".db_escape($tax_id).","
432                                 .db_escape($rate).",".db_escape($ex_rate).",".($included ? 1:0).","
433                                 .db_escape($net_amount).","
434                                 .db_escape($amount).",".db_escape($memo).",".db_escape($reg_type, true).")";
435
436         db_query($sql, "Cannot save trans tax details");
437
438 }
439 //----------------------------------------------------------------------------------------
440
441 function get_trans_tax_details($trans_type, $trans_no)
442 {
443         $sql = "SELECT ".TB_PREF."trans_tax_details.*, "
444                 .TB_PREF."tax_types.name AS tax_type_name, "
445                 .TB_PREF."trans_tax_details.rate AS effective_rate, "
446                 .TB_PREF."tax_types.rate AS rate
447                 FROM ".TB_PREF."trans_tax_details,".TB_PREF."tax_types
448                 WHERE trans_type = ".db_escape($trans_type)."
449                 AND trans_no = ".db_escape($trans_no)."
450                 AND (net_amount != 0 OR amount != 0)
451                 AND ".TB_PREF."tax_types.id = ".TB_PREF."trans_tax_details.tax_type_id";
452
453         return db_query($sql, "The transaction tax details could not be retrieved");
454 }
455
456 //----------------------------------------------------------------------------------------
457
458 function void_trans_tax_details($type, $type_no)
459 {
460         $sql = "UPDATE ".TB_PREF."trans_tax_details SET amount=0, net_amount=0
461                 WHERE trans_no=".db_escape($type_no)
462                 ." AND trans_type=".db_escape($type);
463
464         db_query($sql, "The transaction tax details could not be voided");
465 }
466
467 //----------------------------------------------------------------------------------------
468
469 function clear_trans_tax_details($type, $type_no)
470 {
471         $sql = "DELETE FROM ".TB_PREF."trans_tax_details 
472                 WHERE trans_no=".db_escape($type_no)
473                 ." AND trans_type=".db_escape($type);
474
475         db_query($sql, "The transaction tax details could not be cleared");
476 }
477
478 function get_tax_summary($from, $to, $also_zero_purchases=false)
479 {
480         $fromdate = date2sql($from);
481         $todate = date2sql($to);
482
483         $sql = "SELECT 
484                                 SUM(IF(trans_type=".ST_SUPPCREDIT.",-1,1)*IF(taxrec.amount, taxrec.effective_amount/taxrec.amount, 1)*
485                                 IF((reg_type=".TR_OUTPUT.")"
486                                         ." || ((trans_type IN(".ST_SUPPINVOICE.",".ST_SUPPCREDIT.") OR (trans_type=".ST_JOURNAL." AND reg_type=".TR_INPUT."))
487                                         ), net_amount*ex_rate,0)
488                                 ) net_output,
489
490                                 SUM(IF(trans_type=".ST_SUPPCREDIT.",-1,1)*
491                                 IF((reg_type=".TR_OUTPUT.")"
492                                         ." || ((trans_type IN(".ST_SUPPINVOICE.",".ST_SUPPCREDIT.") OR (trans_type=".ST_JOURNAL." AND reg_type=".TR_INPUT."))
493                                         ), amount*ex_rate,0)) payable,
494
495                                 SUM(IF(trans_type IN(".ST_SUPPCREDIT."),-1,1)*
496                                 IF(reg_type=".TR_INPUT
497                                         . ($also_zero_purchases ? '': " AND tax_type_id AND taxrec.rate")
498                                         .", net_amount*ex_rate, 0)) net_input,
499
500                                 SUM(IF(trans_type IN(".ST_SUPPCREDIT."),-1,1)*
501                                 IF(reg_type=".TR_INPUT
502                                         . ($also_zero_purchases ? '': " AND tax_type_id AND taxrec.rate ") 
503                                         .", amount*ex_rate, 0)) collectible,
504                                 taxrec.rate,
505                                 ttype.id,
506                                 ttype.name
507                 FROM ".TB_PREF."trans_tax_details taxrec LEFT JOIN ".TB_PREF."tax_types ttype ON taxrec.tax_type_id=ttype.id
508                         LEFT JOIN ".TB_PREF."tax_groups tgroup ON taxrec.tax_group_id=tgroup.id
509                 WHERE taxrec.trans_type IN (".implode(',',
510                         array(ST_SALESINVOICE, ST_CUSTCREDIT, ST_SUPPINVOICE, ST_SUPPCREDIT, ST_JOURNAL)).")
511                         AND taxrec.tran_date >= '$fromdate'
512                         AND taxrec.tran_date <= '$todate'
513                 GROUP BY ttype.id";
514
515                 // display_error($sql);
516     return db_query($sql,"Cannot retrieve tax summary");
517 }
518 //--------------------------------------------------------------------------------------------------
519
520 function exists_gl_trans($type, $trans_id)
521 {
522         $sql = "SELECT type_no FROM ".TB_PREF."gl_trans WHERE type=".db_escape($type)
523                 ." AND type_no=".db_escape($trans_id);
524         $result = db_query($sql, "Cannot retreive a gl transaction");
525
526     return (db_num_rows($result) > 0);
527 }
528
529 //--------------------------------------------------------------------------------------------------
530
531 function void_gl_trans($type, $trans_id, $nested=false)
532 {
533         if (!$nested)
534                 begin_transaction();
535
536         $sql = "UPDATE ".TB_PREF."gl_trans SET amount=0 WHERE type=".db_escape($type)
537         ." AND type_no=".db_escape($trans_id);
538
539         db_query($sql, "could not void gl transactions for type=$type and trans_no=$trans_id");
540
541         if (!$nested)
542                 commit_transaction();
543 }
544
545 //----------------------------------------------------------------------------------------
546
547 function clear_gl_trans($type, $trans_id, $nested=false)
548 {
549         if (!$nested)
550                 begin_transaction();
551
552         $sql = "DELETE FROM ".TB_PREF."gl_trans WHERE type=".db_escape($type)
553         ." AND type_no=".db_escape($trans_id);
554
555         db_query($sql, "could not clear gl transactions for type=$type and trans_no=$trans_id");
556
557         if (!$nested)
558                 commit_transaction();
559 }
560
561 function get_sql_for_journal_inquiry($filter, $from, $to, $ref='', $memo='', $alsoclosed=false,
562                  $user_id=null, $contractor_id=null, $dimension=null)
563 {
564
565         $sql = "SELECT  IF(ISNULL(a.gl_seq),0,a.gl_seq) as gl_seq,
566                 gl.tran_date,
567                 gl.type as trans_type,
568                 gl.type_no as trans_no,
569                 IFNULL(MAX(supp.supp_name), MAX(cust.name)) as name,
570                 IF(ISNULL(st.supp_reference), '', st.supp_reference) AS supp_reference,
571                 refs.reference,"
572                 .($dimension ? " -SUM(IF(dim.dimension in(gl.dimension_id,gl.dimension2_id), gl.amount, 0)) as amount,":" SUM(IF(gl.amount>0, gl.amount,0)) as amount,")
573                 ."com.memo_,
574                 IF(ISNULL(u.user_id),'',u.user_id) as user_id";
575
576         if ($contractor_id > 0) {
577                 $sql.= ", st.supplier_id, dt.debtor_no ";
578         }
579
580         $sql.= " FROM ".TB_PREF."gl_trans as gl
581                  LEFT JOIN ".TB_PREF."audit_trail as a ON
582                         (gl.type=a.type AND gl.type_no=a.trans_no)
583                  LEFT JOIN ".TB_PREF."comments as com ON
584                         (gl.type=com.type AND gl.type_no=com.id)
585                  LEFT JOIN ".TB_PREF."refs as refs ON
586                         (gl.type=refs.type AND gl.type_no=refs.id)
587                  LEFT JOIN ".TB_PREF."users as u ON
588                         a.user=u.id
589                  LEFT JOIN ".TB_PREF."debtor_trans dt ON dt.type=gl.type AND gl.type_no=dt.trans_no
590                  LEFT JOIN ".TB_PREF."debtors_master cust ON gl.person_type_id=2 AND gl.person_id=cust.debtor_no
591                  LEFT JOIN ".TB_PREF."supp_trans st ON st.type=gl.type AND gl.type_no=st.trans_no
592                  LEFT JOIN ".TB_PREF."suppliers supp ON gl.person_type_id=3 AND gl.person_id=supp.supplier_id"
593                  .($dimension ? 
594                  " LEFT JOIN (SELECT type, type_no, MAX(IFNULL(dimension_id, dimension2_id)) dimension FROM ".TB_PREF."gl_trans GROUP BY type, type_no) dim 
595                                 ON gl.type=dim.type AND gl.type_no=dim.type_no" : '')
596                 ." WHERE gl.tran_date >= '" . date2sql($from) . "'
597                 AND gl.tran_date <= '" . date2sql($to) . "'
598                 AND gl.amount!=0";
599         if ($ref) {
600                 $sql .= " AND refs.reference LIKE ". db_escape("%$ref%");
601         }
602         if ($memo) {
603                 $sql .= " AND com.memo_ LIKE ". db_escape("%$memo%");
604         }
605         if ($filter != -1) {
606                 $sql .= " AND gl.type=".db_escape($filter);
607         }
608         if (!$alsoclosed) {
609                 $sql .= " AND gl_seq=0";
610         }
611         else
612                 $sql .= " AND NOT ISNULL(a.gl_seq)";
613
614         if ($user_id != null)
615                 $sql .= " AND user_id = ".db_escape($user_id);
616
617         if ($contractor_id > 0) {
618                 $sql.= " AND (dt.debtor_no =".$contractor_id;
619                 $sql.= " OR st.supplier_id =".$contractor_id.") ";
620         }       
621
622         if ($dimension != null)
623                 $sql .= " AND dim.dimension = ".db_escape($dimension);
624
625         $sql .= " GROUP BY gl.tran_date, a.gl_seq, gl_seq, gl.type, gl.type_no";
626
627         return $sql;
628 }