1 #=====================================================================
4 # Based on SQL-Ledger Version 2.1.9
5 # Web http://www.lx-office.org
7 #=====================================================================
8 # SQL-Ledger Accounting
11 # Author: Dieter Simader
12 # Email: dsimader@sql-ledger.org
13 # Web: http://www.sql-ledger.org
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.
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., 51 Franklin Street, Fifth Floor, Boston,
30 #======================================================================
32 # Accounts Receivable module backend routines
34 #======================================================================
39 use SL::DATEV qw(:CONSTANTS);
46 use SL::Util qw(trim);
51 sub post_transaction {
52 my ($self, $myconfig, $form, $provided_dbh, %params) = @_;
53 $main::lxdebug->enter_sub();
55 my $rc = SL::DB->client->with_transaction(\&_post_transaction, $self, $myconfig, $form, $provided_dbh, %params);
57 $::lxdebug->leave_sub;
61 sub _post_transaction {
62 my ($self, $myconfig, $form, $provided_dbh, %params) = @_;
64 my $payments_only = $params{payments_only};
66 my ($query, $sth, $null, $taxrate, $amount, $tax);
72 my $dbh = $provided_dbh || SL::DB->client->dbh;
73 $form->{defaultcurrency} = $form->get_default_currency($myconfig);
76 $form->{exchangerate} = ($form->{currency} eq $form->{defaultcurrency}) ? 1 :
77 ( $form->check_exchangerate($myconfig, $form->{currency}, $form->{transdate}, 'buy') ||
78 $form->parse_amount($myconfig, $form->{exchangerate}) );
80 # get the charts selected
81 $form->{AR_amounts}{"amount_$_"} = $form->{"AR_amount_chart_id_$_"} for (1 .. $form->{rowcount});
83 $form->{tax} = 0; # is this still needed?
85 # main calculation of rowcount loop inside Form method, amount_$i and tax_$i get formatted
86 $form->{taxincluded} = 0 unless $form->{taxincluded};
87 ($form->{netamount},$form->{total_tax},$form->{amount}) = $form->calculate_arap('sell', $form->{taxincluded}, $form->{exchangerate});
89 # adjust paidaccounts if there is no date in the last row
90 # this does not apply to stornos, where the paid field is set manually
91 unless ($form->{storno}) {
92 $form->{paidaccounts}-- unless $form->{"datepaid_$form->{paidaccounts}"};
96 for $i (1 .. $form->{paidaccounts}) {
97 $form->{"paid_$i"} = $form->round_amount($form->parse_amount($myconfig, $form->{"paid_$i"}), 2);
98 $form->{paid} += $form->{"paid_$i"};
99 $form->{datepaid} = $form->{"datepaid_$i"};
103 $form->{paid} = $form->round_amount($form->{paid} * ($form->{exchangerate} || 1), 2);
105 $form->get_employee($dbh) unless $form->{employee_id};
107 # if we have an id delete old records else make one
108 if (!$payments_only) {
110 # delete detail records
111 $query = qq|DELETE FROM acc_trans WHERE trans_id = ?|;
112 do_query($form, $dbh, $query, $form->{id});
115 $query = qq|SELECT nextval('glid')|;
116 ($form->{id}) = selectrow_query($form, $dbh, $query);
117 $query = qq|INSERT INTO ar (id, invnumber, employee_id, currency_id, taxzone_id) VALUES (?, 'dummy', ?, (SELECT id FROM currencies WHERE name=?), (SELECT taxzone_id FROM customer WHERE id = ?))|;
118 do_query($form, $dbh, $query, $form->{id}, $form->{employee_id}, $form->{currency}, $form->{customer_id});
119 if (!$form->{invnumber}) {
120 my $trans_number = SL::TransNumber->new(type => 'invoice', dbh => $dbh, number => $form->{partnumber}, id => $form->{id});
121 $form->{invnumber} = $trans_number->create_unique;
126 # amount for AR account
127 $form->{receivables} = $form->round_amount($form->{amount}, 2) * -1;
129 # update exchangerate
130 $form->update_exchangerate($dbh, $form->{currency}, $form->{transdate}, $form->{exchangerate}, 0)
131 if ($form->{currency} ne $form->{defaultcurrency}) && !$form->check_exchangerate($myconfig, $form->{currency}, $form->{transdate}, 'buy');
133 if (!$payments_only) {
136 invnumber = ?, ordnumber = ?, transdate = ?, customer_id = ?,
137 taxincluded = ?, amount = ?, duedate = ?, deliverydate = ?, paid = ?,
138 currency_id = (SELECT id FROM currencies WHERE name = ?),
139 netamount = ?, notes = ?, department_id = ?,
140 employee_id = ?, storno = ?, storno_id = ?, globalproject_id = ?,
143 my @values = ($form->{invnumber}, $form->{ordnumber}, conv_date($form->{transdate}), conv_i($form->{customer_id}), $form->{taxincluded} ? 't' : 'f', $form->{amount},
144 conv_date($form->{duedate}), conv_date($form->{deliverydate}), $form->{paid},
146 $form->{netamount}, $form->{notes}, conv_i($form->{department_id}),
147 conv_i($form->{employee_id}), $form->{storno} ? 't' : 'f', $form->{storno_id},
148 conv_i($form->{globalproject_id}), $form->{direct_debit} ? 't' : 'f', conv_i($form->{id}));
149 do_query($form, $dbh, $query, @values);
151 # add individual transactions for AR, amount and taxes
152 for $i (1 .. $form->{rowcount}) {
153 if ($form->{"amount_$i"} != 0) {
154 my $project_id = conv_i($form->{"project_id_$i"});
156 # insert detail records in acc_trans
157 $query = qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, project_id, taxkey, tax_id, chart_link)
158 VALUES (?, ?, ?, ?, ?, ?, ?, (SELECT c.link FROM chart c WHERE c.id = ?))|;
159 @values = (conv_i($form->{id}), $form->{AR_amounts}{"amount_$i"}, conv_i($form->{"amount_$i"}), conv_date($form->{transdate}), $project_id,
160 conv_i($form->{"taxkey_$i"}), conv_i($form->{"tax_id_$i"}), $form->{AR_amounts}{"amount_$i"});
161 do_query($form, $dbh, $query, @values);
163 if ($form->{"tax_$i"} != 0) {
164 # insert detail records in acc_trans
165 $query = qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, project_id, taxkey, tax_id, chart_link)
166 VALUES (?, (SELECT c.id FROM chart c WHERE c.accno = ?), ?, ?, ?, ?, ?, (SELECT c.link FROM chart c WHERE c.accno = ?))|;
167 @values = (conv_i($form->{id}), $form->{AR_amounts}{"tax_$i"}, conv_i($form->{"tax_$i"}), conv_date($form->{transdate}), $project_id,
168 conv_i($form->{"taxkey_$i"}), conv_i($form->{"tax_id_$i"}), $form->{AR_amounts}{"tax_$i"});
169 do_query($form, $dbh, $query, @values);
175 $query = qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, taxkey, tax_id, chart_link)
176 VALUES (?, ?, ?, ?, (SELECT taxkey_id FROM chart WHERE id = ?),
181 ORDER BY startdate DESC LIMIT 1),
182 (SELECT c.link FROM chart c WHERE c.id = ?))|;
183 @values = (conv_i($form->{id}), $form->{AR_chart_id}, conv_i($form->{receivables}), conv_date($form->{transdate}),
184 $form->{AR_chart_id}, $form->{AR_chart_id}, conv_date($form->{transdate}), $form->{AR_chart_id});
185 do_query($form, $dbh, $query, @values);
188 # Record paid amount.
189 $query = qq|UPDATE ar SET paid = ?, datepaid = ? WHERE id = ?|;
190 do_query($form, $dbh, $query, $form->{paid}, $form->{paid} ? conv_date($form->{datepaid}) : undef, conv_i($form->{id}));
193 $form->new_lastmtime('ar');
195 my %already_cleared = %{ $params{already_cleared} // {} };
197 # add paid transactions
198 for my $i (1 .. $form->{paidaccounts}) {
200 if ($form->{"acc_trans_id_$i"} && $payments_only && (SL::DB::Default->get->payments_changeable == 0)) {
204 if ($form->{"paid_$i"} != 0) {
205 my $project_id = conv_i($form->{"paid_project_id_$i"});
207 $form->{"AR_paid_$i"} =~ s/\"//g;
208 ($form->{AR}{"paid_$i"}) = split(/--/, $form->{"AR_paid_$i"});
209 $form->{"datepaid_$i"} = $form->{transdate}
210 unless ($form->{"datepaid_$i"});
212 $form->{"exchangerate_$i"} = ($form->{currency} eq $form->{defaultcurrency}) ? 1 :
213 ( $form->check_exchangerate($myconfig, $form->{currency}, $form->{"datepaid_$i"}, 'buy') ||
214 $form->parse_amount($myconfig, $form->{"exchangerate_$i"}) );
216 # if there is no amount and invtotal is zero there is no exchangerate
217 $form->{exchangerate} = $form->{"exchangerate_$i"}
218 if ($form->{amount} == 0 && $form->{netamount} == 0);
220 my $new_cleared = !$form->{"acc_trans_id_$i"} ? 'f'
221 : !$already_cleared{$form->{"acc_trans_id_$i"}} ? 'f'
222 : $already_cleared{$form->{"acc_trans_id_$i"}}->{amount} != $form->{"paid_$i"} * -1 ? 'f'
223 : $already_cleared{$form->{"acc_trans_id_$i"}}->{accno} != $form->{AR}{"paid_$i"} ? 'f'
224 : $already_cleared{$form->{"acc_trans_id_$i"}}->{cleared} ? 't'
228 $amount = $form->round_amount($form->{"paid_$i"} * $form->{exchangerate}, 2);
232 $query = qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, project_id, cleared, taxkey, tax_id, chart_link)
233 VALUES (?, ?, ?, ?, ?, ?, (SELECT taxkey_id FROM chart WHERE id = ?),
238 ORDER BY startdate DESC LIMIT 1),
239 (SELECT c.link FROM chart c WHERE c.id = ?))|;
240 @values = (conv_i($form->{id}), $form->{AR_chart_id}, $amount, conv_date($form->{"datepaid_$i"}), $project_id, $new_cleared,
241 $form->{AR_chart_id}, $form->{AR_chart_id}, conv_date($form->{"datepaid_$i"}), $form->{AR_chart_id});
243 do_query($form, $dbh, $query, @values);
246 if ($form->{"paid_$i"} != 0) {
248 my $project_id = conv_i($form->{"paid_project_id_$i"});
249 my $gldate = (conv_date($form->{"gldate_$i"}))? conv_date($form->{"gldate_$i"}) : conv_date($form->current_date($myconfig));
250 $amount = $form->{"paid_$i"} * -1;
251 $query = qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, gldate, source, memo, project_id, cleared, taxkey, tax_id, chart_link)
252 VALUES (?, (SELECT id FROM chart WHERE accno = ?), ?, ?, ?, ?, ?, ?, ?, (SELECT taxkey_id FROM chart WHERE accno = ?),
255 WHERE chart_id= (SELECT id
259 ORDER BY startdate DESC LIMIT 1),
260 (SELECT c.link FROM chart c WHERE c.accno = ?))|;
261 @values = (conv_i($form->{id}), $form->{AR}{"paid_$i"}, $amount, conv_date($form->{"datepaid_$i"}), $gldate, $form->{"source_$i"}, $form->{"memo_$i"}, $project_id, $new_cleared, $form->{AR}{"paid_$i"},
262 $form->{AR}{"paid_$i"}, conv_date($form->{"datepaid_$i"}), $form->{AR}{"paid_$i"});
263 do_query($form, $dbh, $query, @values);
265 # exchangerate difference for payment
266 $amount = $form->round_amount( $form->{"paid_$i"} * ($form->{"exchangerate_$i"} - 1) * -1, 2);
269 $query = qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, fx_transaction, cleared, project_id, taxkey, tax_id, chart_link)
270 VALUES (?, (SELECT id FROM chart WHERE accno = ?), ?, ?, 't', 'f', ?, (SELECT taxkey_id FROM chart WHERE accno = ?),
273 WHERE chart_id= (SELECT id
277 ORDER BY startdate DESC LIMIT 1),
278 (SELECT c.link FROM chart c WHERE c.accno = ?))|;
279 @values = (conv_i($form->{id}), $form->{AR}{"paid_$i"}, $amount, conv_date($form->{"datepaid_$i"}), $project_id, $form->{AR}{"paid_$i"},
280 $form->{AR}{"paid_$i"}, conv_date($form->{"datepaid_$i"}), $form->{AR}{"paid_$i"});
281 do_query($form, $dbh, $query, @values);
284 # exchangerate gain/loss
285 $amount = $form->round_amount( $form->{"paid_$i"} * ($form->{exchangerate} - $form->{"exchangerate_$i"}) * -1, 2);
288 # fetch fxgain and fxloss chart info from defaults if charts aren't already filled in form
289 if ( !$form->{fxgain_accno} && $::instance_conf->get_fxgain_accno_id ) {
290 $form->{fxgain_accno} = SL::DB::Manager::Chart->find_by(id => $::instance_conf->get_fxgain_accno_id)->accno;
292 if ( !$form->{fxloss_accno} && $::instance_conf->get_fxloss_accno_id ) {
293 $form->{fxloss_accno} = SL::DB::Manager::Chart->find_by(id => $::instance_conf->get_fxloss_accno_id)->accno;
295 die "fxloss_accno missing" if $amount < 0 and not $form->{fxloss_accno};
296 die "fxgain_accno missing" if $amount > 0 and not $form->{fxgain_accno};
297 my $accno = ($amount > 0) ? $form->{fxgain_accno} : $form->{fxloss_accno};
298 $query = qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, fx_transaction, cleared, project_id, taxkey, tax_id, chart_link)
299 VALUES (?, (SELECT id FROM chart WHERE accno = ?), ?, ?, 't', 'f', ?, (SELECT taxkey_id FROM chart WHERE accno = ?),
302 WHERE chart_id= (SELECT id
306 ORDER BY startdate DESC LIMIT 1),
307 (SELECT c.link FROM chart c WHERE c.accno = ?))|;
308 @values = (conv_i($form->{id}), $accno, $amount, conv_date($form->{"datepaid_$i"}), $project_id, $accno, $accno, conv_date($form->{"datepaid_$i"}), $accno);
309 do_query($form, $dbh, $query, @values);
313 # update exchangerate record
314 $form->update_exchangerate($dbh, $form->{currency}, $form->{"datepaid_$i"}, $form->{"exchangerate_$i"}, 0)
315 if ($form->{currency} ne $form->{defaultcurrency}) && !$form->check_exchangerate($myconfig, $form->{currency}, $form->{"datepaid_$i"}, 'buy');
319 IO->set_datepaid(table => 'ar', id => $form->{id}, dbh => $dbh);
321 if ($form->{draft_id}) {
322 SL::DB::Manager::Draft->delete_all(where => [ id => delete($form->{draft_id}) ]);
325 # safety check datev export
326 if ($::instance_conf->get_datev_check_on_ar_transaction) {
327 my $datev = SL::DATEV->new(
329 trans_id => $form->{id},
332 $datev->generate_datev_data;
334 if ($datev->errors) {
335 die join "\n", $::locale->text('DATEV check returned errors:'), $datev->errors;
342 sub _delete_payments {
343 $main::lxdebug->enter_sub();
345 my ($self, $form, $dbh) = @_;
347 my @delete_acc_trans_ids;
349 # Delete old payment entries from acc_trans.
351 qq|SELECT acc_trans_id
353 WHERE (trans_id = ?) AND fx_transaction
357 SELECT at.acc_trans_id
359 LEFT JOIN chart c ON (at.chart_id = c.id)
360 WHERE (trans_id = ?) AND (c.link LIKE '%AR_paid%')|;
361 push @delete_acc_trans_ids, selectall_array_query($form, $dbh, $query, conv_i($form->{id}), conv_i($form->{id}));
364 qq|SELECT at.acc_trans_id
366 LEFT JOIN chart c ON (at.chart_id = c.id)
368 AND ((c.link = 'AR') OR (c.link LIKE '%:AR') OR (c.link LIKE 'AR:%'))
369 ORDER BY at.acc_trans_id
371 push @delete_acc_trans_ids, selectall_array_query($form, $dbh, $query, conv_i($form->{id}));
373 if (@delete_acc_trans_ids) {
374 $query = qq|DELETE FROM acc_trans WHERE acc_trans_id IN (| . join(", ", @delete_acc_trans_ids) . qq|)|;
375 do_query($form, $dbh, $query);
378 $main::lxdebug->leave_sub();
382 my ($self, $myconfig, $form, $locale) = @_;
383 $main::lxdebug->enter_sub();
385 my $rc = SL::DB->client->with_transaction(\&_post_payment, $self, $myconfig, $form, $locale);
387 $::lxdebug->leave_sub;
392 my ($self, $myconfig, $form, $locale) = @_;
394 my $dbh = SL::DB->client->dbh;
396 my (%payments, $old_form, $row, $item, $query, %keep_vars);
398 $old_form = save_form();
401 SELECT at.acc_trans_id, at.amount, at.cleared, c.accno
403 LEFT JOIN chart c ON (at.chart_id = c.id)
404 WHERE (at.trans_id = ?)
407 my %already_cleared = selectall_as_map($form, $dbh, $query, 'acc_trans_id', [ qw(amount cleared accno) ], $form->{id});
409 # Delete all entries in acc_trans from prior payments.
410 if (SL::DB::Default->get->payments_changeable != 0) {
411 $self->_delete_payments($form, $dbh);
414 # Save the new payments the user made before cleaning up $form.
415 my $payments_re = '^datepaid_\d+$|^gldate_\d+$|^acc_trans_id_\d+$|^memo_\d+$|^source_\d+$|^exchangerate_\d+$|^paid_\d+$|^paid_project_id_\d+$|^AR_paid_\d+$|^paidaccounts$';
416 map { $payments{$_} = $form->{$_} } grep m/$payments_re/, keys %{ $form };
418 # Clean up $form so that old content won't tamper the results.
419 %keep_vars = map { $_, 1 } qw(login password id);
420 map { delete $form->{$_} unless $keep_vars{$_} } keys %{ $form };
422 # Retrieve the invoice from the database.
423 $form->create_links('AR', $myconfig, 'customer', $dbh);
425 # Restore the payment options from the user input.
426 map { $form->{$_} = $payments{$_} } keys %payments;
428 # Set up the content of $form in the way that AR::post_transaction() expects.
430 $self->setup_form($form, 1);
432 $form->{exchangerate} = $form->format_amount($myconfig, $form->{exchangerate});
433 $form->{defaultcurrency} = $form->get_default_currency($myconfig);
435 # Get the AR chart ID (which is normally done by Form::create_links()).
439 LEFT JOIN chart c ON (at.chart_id = c.id)
441 AND ((c.link = 'AR') OR (c.link LIKE '%:AR') OR (c.link LIKE 'AR:%'))
442 ORDER BY at.acc_trans_id
445 ($form->{AR_chart_id}) = selectfirst_array_query($form, $dbh, $query, conv_i($form->{id}));
447 # Post the new payments.
448 $self->post_transaction($myconfig, $form, $dbh, payments_only => 1, already_cleared => \%already_cleared);
450 restore_form($old_form);
455 sub delete_transaction {
456 $main::lxdebug->enter_sub();
458 my ($self, $myconfig, $form) = @_;
460 SL::DB->client->with_transaction(sub {
461 # acc_trans entries are deleted by database triggers.
462 my $query = qq|DELETE FROM ar WHERE id = ?|;
463 do_query($form, SL::DB->client->dbh, $query, $form->{id});
465 }) or do { die SL::DB->client->error };
467 $main::lxdebug->leave_sub();
472 sub ar_transactions {
473 $main::lxdebug->enter_sub();
475 my ($self, $myconfig, $form) = @_;
477 # connect to database
478 my $dbh = $form->get_standard_dbh($myconfig);
483 qq|SELECT DISTINCT a.id, a.invnumber, a.ordnumber, a.cusordnumber, a.transdate, | .
484 qq| a.duedate, a.netamount, a.amount, a.paid, | .
485 qq| a.invoice, a.datepaid, a.notes, a.shipvia, | .
486 qq| a.shippingpoint, a.storno, a.storno_id, a.globalproject_id, | .
487 qq| a.marge_total, a.marge_percent, | .
488 qq| a.transaction_description, a.direct_debit, | .
489 qq| pr.projectnumber AS globalprojectnumber, | .
490 qq| c.name, c.customernumber, c.country, c.ustid, b.description as customertype, | .
491 qq| c.id as customer_id, | .
492 qq| e.name AS employee, | .
493 qq| e2.name AS salesman, | .
494 qq| dc.dunning_description, | .
495 qq| tz.description AS taxzone, | .
496 qq| pt.description AS payment_terms, | .
497 qq| d.description AS department, | .
498 qq{ ( SELECT ch.accno || ' -- ' || ch.description
500 LEFT JOIN chart ch ON ch.id = at.chart_id
501 WHERE ch.link ~ 'AR[[:>:]]'
502 AND at.trans_id = a.id
506 qq|JOIN customer c ON (a.customer_id = c.id) | .
507 qq|LEFT JOIN contacts cp ON (a.cp_id = cp.cp_id) | .
508 qq|LEFT JOIN employee e ON (a.employee_id = e.id) | .
509 qq|LEFT JOIN employee e2 ON (a.salesman_id = e2.id) | .
510 qq|LEFT JOIN dunning_config dc ON (a.dunning_config_id = dc.id) | .
511 qq|LEFT JOIN project pr ON (a.globalproject_id = pr.id)| .
512 qq|LEFT JOIN tax_zones tz ON (tz.id = a.taxzone_id)| .
513 qq|LEFT JOIN payment_terms pt ON (pt.id = a.payment_id)| .
514 qq|LEFT JOIN business b ON (b.id = c.business_id)| .
515 qq|LEFT JOIN department d ON (d.id = a.department_id)|;
520 # - Always return invoices & AR transactions for projects the employee has "view invoices" permissions for, no matter what the other rules say.
521 # - Exclude AR transactions if no permissions for them exist.
522 # - Limit to own invoices unless may edit all invoices.
523 # - If may edit all, allow filtering by employee/salesman.
524 my (@permission_where, @permission_values);
526 if ($::auth->assert('invoice_edit', 1)) {
527 if (!$::auth->assert('show_ar_transactions', 1) ) {
528 push @permission_where, "NOT invoice = 'f'"; # remove ar transactions from Sales -> Reports -> Invoices
531 if (!$::auth->assert('sales_all_edit', 1)) {
532 # only show own invoices
533 push @permission_where, "a.employee_id = ?";
534 push @permission_values, SL::DB::Manager::Employee->current->id;
537 if ($form->{employee_id}) {
538 push @permission_where, "a.employee_id = ?";
539 push @permission_values, conv_i($form->{employee_id});
541 if ($form->{salesman_id}) {
542 push @permission_where, "a.salesman_id = ?";
543 push @permission_values, conv_i($form->{salesman_id});
548 if (@permission_where || !$::auth->assert('invoice_edit', 1)) {
549 my $permission_where_str = @permission_where ? "OR (" . join(" AND ", map { "($_)" } @permission_where) . ")" : "";
551 AND ( (a.globalproject_id IN (
552 SELECT epi.project_id
553 FROM employee_project_invoices epi
554 WHERE epi.employee_id = ?))
555 $permission_where_str)
557 push @values, SL::DB::Manager::Employee->current->id, @permission_values;
560 if ($form->{customer}) {
561 $where .= " AND c.name ILIKE ?";
562 push(@values, like($form->{customer}));
564 if ($form->{"cp_name"}) {
565 $where .= " AND (cp.cp_name ILIKE ? OR cp.cp_givenname ILIKE ?)";
566 push(@values, (like($form->{"cp_name"}))x2);
568 if ($form->{business_id}) {
569 my $business_id = $form->{business_id};
570 $where .= " AND c.business_id = ?";
571 push(@values, $business_id);
573 if ($form->{department_id}) {
574 $where .= " AND a.department_id = ?";
575 push(@values, $form->{department_id});
577 foreach my $column (qw(invnumber ordnumber cusordnumber notes transaction_description)) {
578 if ($form->{$column}) {
579 $where .= " AND a.$column ILIKE ?";
580 push(@values, like($form->{$column}));
583 if ($form->{"project_id"}) {
585 qq|AND ((a.globalproject_id = ?) OR EXISTS | .
586 qq| (SELECT * FROM invoice i | .
587 qq| WHERE i.project_id = ? AND i.trans_id = a.id) | .
589 qq| (SELECT * FROM acc_trans at | .
590 qq| WHERE at.project_id = ? AND at.trans_id = a.id)| .
592 push(@values, $form->{project_id}, $form->{project_id}, $form->{project_id});
595 if ($form->{transdatefrom}) {
596 $where .= " AND a.transdate >= ?";
597 push(@values, trim($form->{transdatefrom}));
599 if ($form->{transdateto}) {
600 $where .= " AND a.transdate <= ?";
601 push(@values, trim($form->{transdateto}));
603 if ($form->{duedatefrom}) {
604 $where .= " AND a.duedate >= ?";
605 push(@values, trim($form->{duedatefrom}));
607 if ($form->{duedateto}) {
608 $where .= " AND a.duedate <= ?";
609 push(@values, trim($form->{duedateto}));
611 if ($form->{open} || $form->{closed}) {
612 unless ($form->{open} && $form->{closed}) {
613 $where .= " AND a.amount <> a.paid" if ($form->{open});
614 $where .= " AND a.amount = a.paid" if ($form->{closed});
618 if ($form->{parts_partnumber}) {
621 SELECT invoice.trans_id
623 LEFT JOIN parts ON (invoice.parts_id = parts.id)
624 WHERE (invoice.trans_id = a.id)
625 AND (parts.partnumber ILIKE ?)
629 push @values, like($form->{parts_partnumber});
632 if ($form->{parts_description}) {
635 SELECT invoice.trans_id
637 WHERE (invoice.trans_id = a.id)
638 AND (invoice.description ILIKE ?)
642 push @values, like($form->{parts_description});
645 if ($form->{show_not_mailed}) {
650 WHERE (rl.from_id = a.id)
651 AND (rl.to_table = 'email_journal')
657 if ($form->{show_marked_as_closed}) {
660 SELECT SUM(acc_trans.amount) AS amount, trans_id
662 LEFT JOIN chart ON chart.id = chart_id
663 WHERE chart.link ILIKE ?
665 ) AS paid_difference ON (paid_difference.trans_id = a.id)
667 unshift @values, '%AR_paid%';
668 $where .= ' AND COALESCE(paid_difference.amount, 0) + a.paid != 0';
671 my ($cvar_where, @cvar_values) = CVar->build_filter_query('module' => 'CT',
672 'trans_id_field' => 'c.id',
676 $where .= qq| AND ($cvar_where)|;
677 push @values, @cvar_values;
680 my @a = qw(transdate invnumber name);
681 push @a, "employee" if $form->{l_employee};
682 my $sortdir = !defined $form->{sortdir} ? 'ASC' : $form->{sortdir} ? 'ASC' : 'DESC';
683 my $sortorder = join(', ', map { "$_ $sortdir" } @a);
685 if (grep({ $_ eq $form->{sort} } qw(id transdate duedate invnumber ordnumber cusordnumber name datepaid employee shippingpoint shipvia transaction_description department))) {
686 $sortorder = $form->{sort} . " $sortdir";
689 $query .= " WHERE $where ORDER BY $sortorder";
691 my @result = selectall_hashref_query($form, $dbh, $query, @values);
693 $form->{AR} = [ @result ];
695 $main::lxdebug->leave_sub();
699 $main::lxdebug->enter_sub();
701 my ($self, $myconfig, $form) = @_;
703 # connect to database
704 my $dbh = SL::DB->client->dbh;
708 " (SELECT transdate FROM ar WHERE id = " .
709 " (SELECT MAX(id) FROM ar) LIMIT 1), " .
711 ($form->{transdate}) = $dbh->selectrow_array($query);
713 $main::lxdebug->leave_sub();
717 $main::lxdebug->enter_sub();
719 my ($self, $form, $for_post_payments) = @_;
721 my ($exchangerate, $akey, $j, $k, $index, $taxamount, $totaltax, $taxrate, $diff, $totalwithholding, $withholdingrate,
725 $form->{forex} = $form->{exchangerate};
726 $exchangerate = $form->{exchangerate} ? $form->{exchangerate} : 1;
728 # expected keys: AR, AR_paid, AR_tax, AR_amount
729 foreach my $key (keys %{ $form->{AR_links} }) {
733 # if there is a value we have an old entry
734 next unless $form->{acc_trans}{$key};
736 # do not use old entries for payments. They come from the form
737 # even if they are not changeable (then they are in hiddens)
738 next if $for_post_payments && $key eq "AR_paid";
740 for my $i (1 .. scalar @{ $form->{acc_trans}{$key} }) {
741 if ($key eq "AR_paid") {
743 $form->{"AR_paid_$j"} = $form->{acc_trans}{$key}->[$i-1]->{accno};
745 $form->{"acc_trans_id_$j"} = $form->{acc_trans}{$key}->[$i - 1]->{acc_trans_id};
747 $form->{"paid_$j"} = $form->{acc_trans}{$key}->[$i - 1]->{amount} * -1;
748 $form->{"datepaid_$j"} = $form->{acc_trans}{$key}->[$i - 1]->{transdate};
749 $form->{"gldate_$j"} = $form->{acc_trans}{$key}->[$i - 1]->{gldate};
750 $form->{"source_$j"} = $form->{acc_trans}{$key}->[$i - 1]->{source};
751 $form->{"memo_$j"} = $form->{acc_trans}{$key}->[$i - 1]->{memo};
752 $form->{"forex_$j"} = $form->{acc_trans}{$key}->[$i - 1]->{exchangerate};
753 $form->{"exchangerate_$i"} = $form->{"forex_$j"};
754 $form->{"paid_project_id_$j"} = $form->{acc_trans}{$key}->[$i - 1]->{project_id};
755 $form->{paidaccounts}++;
757 } else { # e.g. AR_amount, AR, AR_tax
760 $akey =~ s/AR_//; # e.g. tax, amount, AR, used to store form key tax_$i, amount_$i, ...
762 if ($key eq "AR_tax" || $key eq "AP_tax") { # AR_tax
763 $form->{"${key}_$form->{acc_trans}{$key}->[$i-1]->{accno}"} = "$form->{acc_trans}{$key}->[$i-1]->{accno}--$form->{acc_trans}{$key}->[$i-1]->{description}";
764 # determine the rounded tax amounts for each account, e.g. tax_1776
765 $form->{"${akey}_$form->{acc_trans}{$key}->[$i-1]->{accno}"} = $form->round_amount($form->{acc_trans}{$key}->[$i - 1]->{amount} / $exchangerate, 2);
767 # check e.g. $form->{1776_rate}, does this make sense for AR_tax charts? Is this ever valid? If it was, totaltax would be calculated twice
768 if ($form->{"$form->{acc_trans}{$key}->[$i-1]->{accno}_rate"} > 0) {
769 $totaltax += $form->{"${akey}_$form->{acc_trans}{$key}->[$i-1]->{accno}"};
770 $taxrate += $form->{"$form->{acc_trans}{$key}->[$i-1]->{accno}_rate"};
773 $totalwithholding += $form->{"${akey}_$form->{acc_trans}{$key}->[$i-1]->{accno}"};
774 $withholdingrate += $form->{"$form->{acc_trans}{$key}->[$i-1]->{accno}_rate"};
777 $index = $form->{acc_trans}{$key}->[$i - 1]->{index};
778 $form->{"tax_$index"} = $form->round_amount($form->{acc_trans}{$key}->[$i - 1]->{amount} / $exchangerate, 2); # convert the tax_$i amounts
779 # currently totaltax is the sum of rounded tax amounts, is this correct?
780 $totaltax += $form->{"tax_$index"};
782 } else { # e.g. AR_amount, AR
784 $form->{"${akey}_$k"} = $form->round_amount($form->{acc_trans}{$key}->[$i - 1]->{amount} / $exchangerate, 2);
786 if ($akey eq 'amount') {
788 $totalamount += $form->{"${akey}_$i"};
790 $form->{"oldprojectnumber_$k"} = $form->{acc_trans}{$key}->[$i-1]->{projectnumber};
791 $form->{"projectnumber_$k"} = $form->{acc_trans}{$key}->[$i-1]->{projectnumber};
792 $form->{taxrate} = $form->{acc_trans}{$key}->[$i - 1]->{rate};
793 $form->{"project_id_$k"} = $form->{acc_trans}{$key}->[$i-1]->{project_id};
795 $form->{"${key}_chart_id_$k"} = $form->{acc_trans}{$key}->[$i-1]->{chart_id};
796 $form->{"taxchart_$k"} = $form->{acc_trans}{$key}->[$i-1]->{id} . "--" . $form->{acc_trans}{$key}->[$i-1]->{rate};
803 $form->{paidaccounts} = 1 if not defined $form->{paidaccounts};
805 if ($form->{taxincluded} && $form->{taxrate} && $totalamount) {
807 # add tax to amounts and invtotal
808 for my $i (1 .. $form->{rowcount}) {
809 $taxamount = ($totaltax + $totalwithholding) * $form->{"amount_$i"} / $totalamount;
810 $tax = $form->round_amount($taxamount, 2);
811 $diff += ($taxamount - $tax);
812 $form->{"amount_$i"} += $form->{"tax_$i"};
814 $form->{amount_1} += $form->round_amount($diff, 2);
817 $taxamount = $form->round_amount($taxamount, 2);
818 $form->{tax} = $taxamount;
820 $form->{invtotal} = $totalamount + $totaltax;
822 $main::lxdebug->leave_sub();
826 my ($self, $form, $myconfig, $id) = @_;
827 $main::lxdebug->enter_sub();
829 my $rc = SL::DB->client->with_transaction(\&_storno, $self, $form, $myconfig, $id);
831 $::lxdebug->leave_sub;
837 my ($self, $form, $myconfig, $id) = @_;
839 my ($query, $new_id, $storno_row, $acc_trans_rows);
840 my $dbh = SL::DB->client->dbh;
842 $query = qq|SELECT nextval('glid')|;
843 ($new_id) = selectrow_query($form, $dbh, $query);
845 $query = qq|SELECT * FROM ar WHERE id = ?|;
846 $storno_row = selectfirst_hashref_query($form, $dbh, $query, $id);
848 $storno_row->{id} = $new_id;
849 $storno_row->{storno_id} = $id;
850 $storno_row->{storno} = 't';
851 $storno_row->{invnumber} = 'Storno-' . $storno_row->{invnumber};
852 $storno_row->{amount} *= -1;
853 $storno_row->{netamount} *= -1;
854 $storno_row->{paid} = $storno_row->{amount};
856 delete @$storno_row{qw(itime mtime)};
858 $query = sprintf 'INSERT INTO ar (%s) VALUES (%s)', join(', ', keys %$storno_row), join(', ', map '?', values %$storno_row);
859 do_query($form, $dbh, $query, (values %$storno_row));
861 $query = qq|UPDATE ar SET paid = amount + paid, storno = 't' WHERE id = ?|;
862 do_query($form, $dbh, $query, $id);
864 $form->new_lastmtime('ar') if $id == $form->{id};
866 # now copy acc_trans entries
867 $query = qq|SELECT a.*, c.link FROM acc_trans a LEFT JOIN chart c ON a.chart_id = c.id WHERE a.trans_id = ? ORDER BY a.acc_trans_id|;
868 my $rowref = selectall_hashref_query($form, $dbh, $query, $id);
870 # kill all entries containing payments, which are the last 2n rows, of which the last has link =~ /paid/
871 while ($rowref->[-1]{link} =~ /paid/) {
872 splice(@$rowref, -2);
875 for my $row (@$rowref) {
876 delete @$row{qw(itime mtime link acc_trans_id)};
877 $query = sprintf 'INSERT INTO acc_trans (%s) VALUES (%s)', join(', ', keys %$row), join(', ', map '?', values %$row);
878 $row->{trans_id} = $new_id;
879 $row->{amount} *= -1;
880 do_query($form, $dbh, $query, (values %$row));
883 map { IO->set_datepaid(table => 'ar', id => $_, dbh => $dbh) } ($id, $new_id);