Umformatieren der Abfragen und Vermeidung von SQL injection durch Verwendung von...
[kivitendo-erp.git] / SL / AR.pm
1 #=====================================================================
2 # LX-Office ERP
3 # Copyright (C) 2004
4 # Based on SQL-Ledger Version 2.1.9
5 # Web http://www.lx-office.org
6 #
7 #=====================================================================
8 # SQL-Ledger Accounting
9 # Copyright (C) 2001
10 #
11 #  Author: Dieter Simader
12 #   Email: dsimader@sql-ledger.org
13 #     Web: http://www.sql-ledger.org
14 #
15 #  Contributors:
16 #
17 # This program is free software; you can redistribute it and/or modify
18 # it under the terms of the GNU General Public License as published by
19 # the Free Software Foundation; either version 2 of the License, or
20 # (at your option) any later version.
21 #
22 # This program is distributed in the hope that it will be useful,
23 # but WITHOUT ANY WARRANTY; without even the implied warranty of
24 # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
25 # GNU General Public License for more details.
26 # You should have received a copy of the GNU General Public License
27 # along with this program; if not, write to the Free Software
28 # Foundation, Inc., 675 Mass Ave, Cambridge, MA 02139, USA.
29 #======================================================================
30 #
31 # Accounts Receivable module backend routines
32 #
33 #======================================================================
34
35 package AR;
36
37 use Data::Dumper;
38 use SL::DBUtils;
39
40 sub post_transaction {
41   $main::lxdebug->enter_sub();
42
43   my ($self, $myconfig, $form) = @_;
44
45   my ($null, $taxrate, $amount, $tax, $diff);
46   my $exchangerate = 0;
47   my $i;
48
49   my @values;
50
51   my $dbh = $form->dbconnect_noauto($myconfig);
52
53   if ($form->{currency} eq $form->{defaultcurrency}) {
54     $form->{exchangerate} = 1;
55   } else {
56     $exchangerate =
57       $form->check_exchangerate($myconfig, $form->{currency},
58                                 $form->{transdate}, 'buy');
59   }
60   for $i (1 .. $form->{rowcount}) {
61     $form->{AR_amounts}{"amount_$i"} =
62       (split(/--/, $form->{"AR_amount_$i"}))[0];
63   }
64   ($form->{AR_amounts}{receivables}) = split(/--/, $form->{ARselected});
65   ($form->{AR}{receivables})         = split(/--/, $form->{ARselected});
66
67   $form->{exchangerate} =
68     ($exchangerate)
69     ? $exchangerate
70     : $form->parse_amount($myconfig, $form->{exchangerate});
71
72   for $i (1 .. $form->{rowcount}) {
73
74     $form->{"amount_$i"} =
75       $form->round_amount($form->parse_amount($myconfig, $form->{"amount_$i"})
76                             * $form->{exchangerate},
77                           2);
78
79     $form->{netamount} += $form->{"amount_$i"};
80
81     # parse tax_$i for later
82     $form->{"tax_$i"} = $form->parse_amount($myconfig, $form->{"tax_$i"});
83   }
84
85   # this is for ar
86
87   $form->{amount} = $form->{netamount};
88
89   $form->{tax}       = 0;
90   $form->{netamount} = 0;
91   $form->{total_tax} = 0;
92
93   # taxincluded doesn't make sense if there is no amount
94
95   $form->{taxincluded} = 0 if ($form->{amount} == 0);
96   for $i (1 .. $form->{rowcount}) {
97     ($form->{"tax_id_$i"}, $NULL) = split /--/, $form->{"taxchart_$i"};
98
99     $query =
100       qq|SELECT c.accno, t.taxkey, t.rate | .
101       qq|FROM tax t LEFT JOIN chart c on (c.id = t.chart_id) | .
102       qq|WHERE t.id = ? | .
103       qq|ORDER BY c.accno|;
104
105     ($form->{AR_amounts}{"tax_$i"}, $form->{"taxkey_$i"}, $form->{"taxrate_$i"}) =
106       selectrow_query($form, $dbh, $query, $form->{"tax_id_$i"});
107     $form->{AR_amounts}{"tax_$i"}{taxkey}    = $form->{"taxkey_$i"};
108     $form->{AR_amounts}{"amount_$i"}{taxkey} = $form->{"taxkey_$i"};
109
110     if ($form->{taxincluded} *= 1) {
111       if (!$form->{"korrektur_$i"}) {
112       $tax =
113         $form->{"amount_$i"} -
114         ($form->{"amount_$i"} / ($form->{"taxrate_$i"} + 1));
115       } else {
116         $tax = $form->{"tax_$i"};
117       }
118       $amount = $form->{"amount_$i"} - $tax;
119       $form->{"amount_$i"} = $form->round_amount($amount, 2);
120       $diff += $amount - $form->{"amount_$i"};
121       $form->{"tax_$i"} = $form->round_amount($tax, 2);
122       $form->{netamount} += $form->{"amount_$i"};
123     } else {
124       if (!$form->{"korrektur_$i"}) {
125         $form->{"tax_$i"} = $form->{"amount_$i"} * $form->{"taxrate_$i"};
126       }
127       $form->{"tax_$i"} =
128         $form->round_amount($form->{"tax_$i"} * $form->{exchangerate}, 2);
129       $form->{netamount} += $form->{"amount_$i"};
130     }
131     
132     $form->{total_tax} += $form->{"tax_$i"};
133   }
134
135   # adjust paidaccounts if there is no date in the last row
136   $form->{paidaccounts}-- unless ($form->{"datepaid_$form->{paidaccounts}"});
137   $form->{paid} = 0;
138
139   # add payments
140   for $i (1 .. $form->{paidaccounts}) {
141     $form->{"paid_$i"} =
142       $form->round_amount($form->parse_amount($myconfig, $form->{"paid_$i"}),
143                           2);
144
145     $form->{paid} += $form->{"paid_$i"};
146     $form->{datepaid} = $form->{"datepaid_$i"};
147
148   }
149
150   $form->{amount} = $form->{netamount} + $form->{total_tax};
151   $form->{paid}   =
152     $form->round_amount($form->{paid} * $form->{exchangerate}, 2);
153
154   my ($query, $sth, $null);
155
156   ($null, $form->{employee_id}) = split /--/, $form->{employee};
157   unless ($form->{employee_id}) {
158     $form->get_employee($dbh);
159   }
160
161   # if we have an id delete old records
162   if ($form->{id}) {
163     # delete detail records
164     $query = qq|DELETE FROM acc_trans WHERE trans_id = ?|;
165     do_query($form, $dbh, $query, $form->{id});
166
167   } else {
168     $query = qq|SELECT nextval('glid')|;
169     ($form->{id}) = selectrow_query($form, $dbh, $query);
170
171     $query = qq|INSERT INTO ar (id, invnumber, employee_id) VALUES (?, 'dummy', ?)|;
172     do_query($form, $dbh, $query, $form->{id}, $form->{employee_id});
173   }
174
175   # update department
176   ($null, $form->{department_id}) = split(/--/, $form->{department});
177   $form->{department_id} *= 1;
178
179   # record last payment date in ar table
180   $form->{datepaid} = $form->{transdate} unless $form->{datepaid};
181   my $datepaid = ($form->{paid} != 0) ? $form->{datepaid} : undef;
182
183   $query =
184     qq|UPDATE ar set | .
185     qq|  invnumber = ?, ordnumber = ?, transdate = ?, customer_id = ?, | .
186     qq|  taxincluded = ?, amount = ?, duedate = ?, paid = ?, datepaid = ?, | .
187     qq|  netamount = ?, curr = ?, notes = ?, department_id = ?, | .
188     qq|  employee_id = ? | .
189     qq|WHERE id = ?|;
190   my @values = ($form->{invnumber}, $form->{ordnumber},
191                 conv_date($form->{transdate}), conv_i($form->{customer_id}),
192                 $form->{taxincluded} ? 't' : 'f', $form->{amount},
193                 conv_date($form->{duedate}), $form->{paid},
194                 conv_date($datepaid), $form->{netamount},
195                 $form->{currency}, $form->{notes},
196                 conv_i($form->{department_id}),
197                 conv_i($form->{employee_id}),
198                 conv_i($form->{id}));
199   do_query($form, $dbh, $query, @values);
200
201   # amount for AR account
202   $form->{receivables} = $form->round_amount($form->{amount}, 2) * -1;
203
204   # update exchangerate
205   if (($form->{currency} ne $form->{defaultcurrency}) && !$exchangerate) {
206     $form->update_exchangerate($dbh, $form->{currency}, $form->{transdate},
207                                $form->{exchangerate}, 0);
208   }
209
210   # add individual transactions for AR, amount and taxes
211   for $i (1 .. $form->{rowcount}) {
212     if ($form->{"amount_$i"} != 0) {
213       my $project_id = conv_i($form->{"project_id_$i"});
214       $taxkey = $form->{AR_amounts}{"amount_$i"}{taxkey};
215
216       # insert detail records in acc_trans
217       $query =
218         qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, | .
219         qq|  project_id, taxkey) | .
220         qq|VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), ?, ?, ?, ?)|;
221       @values = (conv_i($form->{id}), conv_i($form->{AR_amounts}{"amount_$i"}),
222                  conv_i($form->{"amount_$i"}), conv_date($form->{transdate}),
223                  $project_id, conv_i($taxkey));
224       do_query($form, $dbh, $query, @values);
225
226       if ($form->{"tax_$i"} != 0) {
227         # insert detail records in acc_trans
228         $query =
229           qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, | .
230           qq|  project_id, taxkey) | .
231           qq|VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), | .
232           qq|  ?, ?, ?, ?)|;
233         @values = (conv_i($form->{id}), conv_i($form->{AR_amounts}{"tax_$i"}),
234                    conv_i($form->{"tax_$i"}), conv_date($form->{transdate}),
235                    $project_id, conv_i($taxkey));
236         do_query($form, $dbh, $query, @values);
237       }
238     }
239   }
240
241   # add recievables
242   $query =
243     qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate) | .
244     qq|VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), ?, ?)|;
245   @values = (conv_i($form->{id}), conv_i($form->{AR_amounts}{receivables}),
246              conv_i($form->{receivables}), conv_date($form->{transdate}));
247   do_query($form, $dbh, $query, @values);
248
249   # add paid transactions
250   for my $i (1 .. $form->{paidaccounts}) {
251     if ($form->{"paid_$i"} != 0) {
252       my $project_id = conv_i($form->{"paid_project_id_$i"});
253
254       $form->{"AR_paid_$i"} =~ s/\"//g;
255       ($form->{AR}{"paid_$i"}) = split(/--/, $form->{"AR_paid_$i"});
256       $form->{"datepaid_$i"} = $form->{transdate}
257         unless ($form->{"datepaid_$i"});
258
259       $exchangerate = 0;
260       if ($form->{currency} eq $form->{defaultcurrency}) {
261         $form->{"exchangerate_$i"} = 1;
262       } else {
263         $exchangerate =
264           $form->check_exchangerate($myconfig, $form->{currency},
265                                     $form->{"datepaid_$i"}, 'buy');
266
267         $form->{"exchangerate_$i"} =
268           ($exchangerate)
269           ? $exchangerate
270           : $form->parse_amount($myconfig, $form->{"exchangerate_$i"});
271       }
272
273       # if there is no amount and invtotal is zero there is no exchangerate
274       if ($form->{amount} == 0 && $form->{netamount} == 0) {
275         $form->{exchangerate} = $form->{"exchangerate_$i"};
276       }
277
278       # receivables amount
279       $amount =
280         $form->round_amount($form->{"paid_$i"} * $form->{exchangerate}, 2);
281
282       if ($form->{receivables} != 0) {
283         # add receivable
284         $query =
285           qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, project_id) | .
286           qq|VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), ?, ?, ?)|;
287         @values = (conv_i($form->{id}), conv_i($form->{AR}{receivables}),
288                    $amount, conv_date($form->{"datepaid_$i"}), $project_id);
289         do_query($form, $dbh, $query, @values);
290       }
291       $form->{receivables} = $amount;
292
293       if ($form->{"paid_$i"} != 0) {
294         my $project_id = conv_i($form->{"paid_project_id_$i"});
295         # add payment
296         $amount = $form->{"paid_$i"} * -1;
297         $query  =
298           qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, source, memo, project_id) | .
299           qq|VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), ?, ?, ?, ?, ?)|;
300         @values = (conv_i($form->{id}), conv_i($form->{AR}{"paid_$i"}), $amount,
301                    conv_date($form->{"datepaid_$i"}), $form->{"source_$i"},
302                    $form->{"memo_$i"}, $project_id);
303         do_query($form, $dbh, $query, @values);
304
305         # exchangerate difference for payment
306         $amount =
307           $form->round_amount(
308                     $form->{"paid_$i"} * ($form->{"exchangerate_$i"} - 1) * -1,
309                     2);
310
311         if ($amount != 0) {
312           $query =
313             qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, fx_transaction, cleared, project_id) | .
314             qq|VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), ?, ?, 't', 'f', ?)|;
315           @values = (conv_i($form->{id}), conv_i($form->{AR}{"paid_$i"}),
316                      $amount, conv_date($form->{"datepaid_$i"}), $project_id);
317           do_query($form, $dbh, $query, @values);
318         }
319
320         # exchangerate gain/loss
321         $amount =
322           $form->round_amount(
323                    $form->{"paid_$i"} *
324                      ($form->{exchangerate} - $form->{"exchangerate_$i"}) * -1,
325                    2);
326
327         if ($amount != 0) {
328           $accno =
329             ($amount > 0) ? $form->{fxgain_accno} : $form->{fxloss_accno};
330           $query =
331             qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, fx_transaction, cleared, project_id) | .
332             qq|VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), ?, ?, 't', 'f', ?)|;
333           @values = (conv_i($form->{id}), $accno, $amount,
334                      conv_date($form->{"datepaid_$i"}), $project_id);
335           do_query($form, $dbh, $query, @values);
336         }
337       }
338
339       # update exchangerate record
340       if (($form->{currency} ne $form->{defaultcurrency}) && !$exchangerate) {
341         $form->update_exchangerate($dbh, $form->{currency},
342                                    $form->{"datepaid_$i"},
343                                    $form->{"exchangerate_$i"}, 0);
344       }
345     }
346   }
347
348   my $rc = $dbh->commit;
349   $dbh->disconnect;
350
351   $main::lxdebug->leave_sub();
352
353   return $rc;
354 }
355
356 sub post_payment {
357   $main::lxdebug->enter_sub();
358
359   my ($self, $myconfig, $form, $locale) = @_;
360
361   # connect to database, turn off autocommit
362   my $dbh = $form->dbconnect_noauto($myconfig);
363
364   $form->{datepaid} = $form->{transdate};
365
366   # total payments, don't move we need it here
367   for my $i (1 .. $form->{paidaccounts}) {
368     if ($form->{type} eq "credit_note") {
369       $form->{"paid_$i"} = $form->parse_amount($myconfig, $form->{"paid_$i"}) * -1;
370     } else {
371       $form->{"paid_$i"} = $form->parse_amount($myconfig, $form->{"paid_$i"});
372     } 
373     $form->{paid} += $form->{"paid_$i"};
374     $form->{datepaid} = $form->{"datepaid_$i"} if ($form->{"datepaid_$i"});
375   }
376
377   $form->{exchangerate} =
378       $form->get_exchangerate($dbh, $form->{currency}, $form->{transdate},
379                               "buy");
380
381   my ($accno_ar) = split(/--/, $form->{ARselected});
382
383   # record payments and offsetting AR
384   for my $i (1 .. $form->{paidaccounts}) {
385
386     if ($form->{"paid_$i"} != 0) {
387       my $project_id = conv_i($form->{"paid_project_id_$i"});
388
389       my ($accno) = split /--/, $form->{"AR_paid_$i"};
390       $form->{"datepaid_$i"} = $form->{transdate}
391         unless ($form->{"datepaid_$i"});
392       $form->{datepaid} = $form->{"datepaid_$i"};
393
394       $exchangerate = 0;
395       if (($form->{currency} eq $form->{defaultcurrency}) || ($form->{defaultcurrency} eq "")) {
396         $form->{"exchangerate_$i"} = 1;
397       } else {
398         $exchangerate =
399           $form->check_exchangerate($myconfig, $form->{currency},
400                                     $form->{"datepaid_$i"}, 'buy');
401
402         $form->{"exchangerate_$i"} =
403           ($exchangerate)
404           ? $exchangerate
405           : $form->parse_amount($myconfig, $form->{"exchangerate_$i"});
406       }
407
408       # record AR
409       $amount =
410         $form->round_amount($form->{"paid_$i"} * $form->{"exchangerate"},
411                             2);
412
413
414       $query =
415         qq|DELETE FROM acc_trans | .
416         qq|WHERE trans_id = ? AND amount = ? AND transdate = ? AND | .
417         qq|  chart_id = (SELECT c.id FROM chart c WHERE c.accno = ?)|;
418       @values = (conv_i($form->{id}), $amount,
419                  conv_date($form->{"datepaid_$i"}), $accno_ar);
420       do_query($form, $dbh, $query, @values);
421
422       $query =
423         qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, project_id) | .
424         qq|VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), ?, ?, ?)|;
425       @values = (conv_i($form->{id}), $accno_ar, conv_i($amount),
426                  conv_date($form->{"datepaid_$i"}), $project_id);
427       do_query($form, $dbh, $query, @values);
428
429       # record payment
430       $form->{"paid_$i"} *= -1;
431
432       $query =
433         qq|DELETE FROM acc_trans | .
434         qq|WHERE trans_id = ? AND | .
435         qq|  chart_id = (SELECT c.id FROM chart c WHERE c.accno = ?) AND | .
436         qq|  amount = ? AND transdate = ? AND source = ? AND memo = ?|;
437       @values = (conv_i($form->{id}), $accno, conv_i($form->{"paid_$i"}),
438                  conv_date($form->{"datepaid_$i"}),
439                  $form->{"source_$i"}, $form->{"memo_$i"});
440       do_query($form, $dbh, $query, @values);
441
442       $query =
443         qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, source, memo, project_id) | .
444         qq|VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), ?, ?, ?, ?, ?)|;
445       @values = (conv_i($form->{id}), $accno, conv_i($form->{"paid_$i"}),
446                  conv_date($form->{"datepaid_$i"}),
447                  $form->{"source_$i"}, $form->{"memo_$i"}, $project_id);
448       do_query($form, $dbh, $query, @values);
449
450       # gain/loss
451       $amount =
452         $form->{"paid_$i"} * $form->{exchangerate} - $form->{"paid_$i"} *
453         $form->{"exchangerate_$i"};
454       if ($amount > 0) {
455         $form->{fx}{ $form->{fxgain_accno} }{ $form->{"datepaid_$i"} } +=
456           $amount;
457       } else {
458         $form->{fx}{ $form->{fxloss_accno} }{ $form->{"datepaid_$i"} } +=
459           $amount;
460       }
461
462       $diff = 0;
463
464       # update exchange rate
465       if (($form->{currency} ne $form->{defaultcurrency}) && !$exchangerate) {
466         $form->update_exchangerate($dbh, $form->{currency},
467                                    $form->{"datepaid_$i"},
468                                    $form->{"exchangerate_$i"}, 0);
469       }
470     }
471   }
472
473   # record exchange rate differences and gains/losses
474   foreach my $accno (keys %{ $form->{fx} }) {
475     foreach my $transdate (keys %{ $form->{fx}{$accno} }) {
476       if (
477           ($form->{fx}{$accno}{$transdate} =
478            $form->round_amount($form->{fx}{$accno}{$transdate}, 2)
479           ) != 0
480         ) {
481         $query =
482           qq|DELETE FROM acc_trans | .
483           qq|WHERE trans_id = ? AND | .
484           qq|  chart_id = (SELECT c.id FROM chart c WHERE c.accno = ?) AND | .
485           qq|  amount = ? AND transdate = ? AND cleared = 'f' AND fx_transaction = 't'|;
486         @values = (conv_i($form->{id}), $accno,
487                    conv_i($form->{fx}{$accno}{$transdate}),
488                    conv_date($transdate));
489         do_query($form, $dbh, $query, @values);
490
491         $query =
492           qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, cleared, fx_transaction, project_id) | .
493           qq|VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), ?, ?, 'f', 't', ?)|;
494         @values = (conv_i($form->{id}), $accno,
495                    conv_i($form->{fx}{$accno}{$transdate}),
496                    conv_date($transdate), $project_id);
497         do_query($form, $dbh, $query, @values);
498       }
499     }
500   }
501   my $datepaid = ($form->{paid}) ? $form->{datepaid} : "NULL";
502
503   # save AR record
504   my $query =
505     qq|UPDATE ar set paid = ?, datepaid = ? WHERE id = ?|;
506   @values = (conv_i($form->{paid}), conv_date($datepaid), conv_i($form->{id}));
507   do_query($form, $dbh, $query, @values);
508
509   my $rc = $dbh->commit;
510   $dbh->disconnect;
511
512   $main::lxdebug->leave_sub();
513
514   return $rc;
515 }
516
517 sub delete_transaction {
518   $main::lxdebug->enter_sub();
519
520   my ($self, $myconfig, $form) = @_;
521
522   # connect to database, turn AutoCommit off
523   my $dbh = $form->dbconnect_noauto($myconfig);
524
525   my $query = qq|DELETE FROM ar WHERE id = ?|;
526   do_query($form, $dbh, $query, $form->{id});
527
528   $query = qq|DELETE FROM acc_trans WHERE trans_id = ?|;
529   do_query($form, $dbh, $query, $form->{id});
530
531   # commit
532   my $rc = $dbh->commit;
533   $dbh->disconnect;
534
535   $main::lxdebug->leave_sub();
536
537   return $rc;
538 }
539
540 sub ar_transactions {
541   $main::lxdebug->enter_sub();
542
543   my ($self, $myconfig, $form) = @_;
544
545   # connect to database
546   my $dbh = $form->dbconnect($myconfig);
547
548   my @values;
549
550   my $query =
551     qq|SELECT a.id, a.invnumber, a.ordnumber, a.transdate, | .
552     qq|  a.duedate, a.netamount, a.amount, a.paid, | .
553     qq|  a.invoice, a.datepaid, a.terms, a.notes, a.shipvia, | .
554     qq|  a.shippingpoint, a.storno, a.globalproject_id, | .
555     qq|  pr.projectnumber AS globalprojectnumber, | .
556     qq|  c.name, | .
557     qq|  e.name AS employee | .
558     qq|FROM ar a | .
559     qq|JOIN customer c ON (a.customer_id = c.id) | .
560     qq|LEFT JOIN employee e ON (a.employee_id = e.id) | .
561     qq|LEFT JOIN project pr ON (a.globalproject_id = pr.id)|;
562
563   my $where = "1 = 1";
564   if ($form->{customer_id}) {
565     $where .= " AND a.customer_id = ?";
566     push(@values, $form->{customer_id});
567   } elsif ($form->{customer}) {
568     $where .= " AND c.name ILIKE ?";
569     push(@values, $form->like($form->{customer}));
570   }
571   if ($form->{department}) {
572     my ($null, $department_id) = split /--/, $form->{department};
573     $where .= " AND a.department_id = ?";
574     push(@values, $department_id);
575   }
576   foreach my $column (qw(invnumber ordnumber notes)) {
577     if ($form->{$column}) {
578       $where .= " AND a.$column ILIKE ?";
579       push(@values, $form->like($form->{$column}));
580     }
581   }
582   if ($form->{"project_id"}) {
583     $where .=
584       qq|AND ((a.globalproject_id = ?) OR EXISTS | .
585       qq|  (SELECT * FROM invoice i | .
586       qq|   WHERE i.project_id = ? AND i.trans_id = a.id))|;
587     push(@values, $form->{"project_id"}, $form->{"project_id"});
588   }
589
590   if ($form->{transdatefrom}) {
591     $where .= " AND a.transdate >= ?";
592     push(@values, $form->{transdatefrom});
593   }
594   if ($form->{transdateto}) {
595     $where .= " AND a.transdate <= ?";
596     push(@values, $form->{transdateto});
597   }
598   if ($form->{open} || $form->{closed}) {
599     unless ($form->{open} && $form->{closed}) {
600       $where .= " AND a.amount <> a.paid" if ($form->{open});
601       $where .= " AND a.amount = a.paid"  if ($form->{closed});
602     }
603   }
604
605   my @a = (transdate, invnumber, name);
606   push @a, "employee" if $form->{l_employee};
607   my $sortorder = join(', ', @a);
608   $sortorder = $form->{sort} if ($form->{sort} && grep({ $_ eq $form->{sort} } @a));
609
610   $query .= " WHERE $where ORDER by $sortorder";
611
612   my $sth = $dbh->prepare($query);
613   $sth->execute(@values) ||
614     $form->dberror($query . " (" . join(", ", @values) . ")");
615
616   $form->{AR} = [];
617   while (my $ar = $sth->fetchrow_hashref(NAME_lc)) {
618     push @{ $form->{AR} }, $ar;
619   }
620
621   $sth->finish;
622   $dbh->disconnect;
623
624   $main::lxdebug->leave_sub();
625 }
626
627 sub get_transdate {
628   $main::lxdebug->enter_sub();
629
630   my ($self, $myconfig, $form) = @_;
631
632   # connect to database
633   my $dbh = $form->dbconnect($myconfig);
634
635   my $query =
636     "SELECT COALESCE(" .
637     "  (SELECT transdate FROM ar WHERE id = " .
638     "    (SELECT MAX(id) FROM ar) LIMIT 1), " .
639     "  current_date)";
640   ($form->{transdate}) = $dbh->selectrow_array($query);
641
642   $dbh->disconnect;
643
644   $main::lxdebug->leave_sub();
645 }
646
647 1;
648