1 #======================================================================
4 # Based on SQL-Ledger Version 2.1.9
5 # Web http://www.lx-office.org
7 #=====================================================================
8 # SQL-Ledger Accounting
9 # Copyright (C) 1998-2002
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., 675 Mass Ave, Cambridge, MA 02139, USA.
29 #======================================================================
31 # Dunning process module
33 #======================================================================
40 use SL::GenericTranslations;
52 $main::lxdebug->enter_sub();
54 my ($self, $myconfig, $form) = @_;
57 my $dbh = $form->dbconnect($myconfig);
61 qq|FROM dunning_config | .
62 qq|ORDER BY dunning_level|;
63 $form->{DUNNING} = selectall_hashref_query($form, $dbh, $query);
65 foreach my $ref (@{ $form->{DUNNING} }) {
66 $ref->{fee} = $form->format_amount($myconfig, $ref->{fee}, 2);
67 $ref->{interest_rate} = $form->format_amount($myconfig, ($ref->{interest_rate} * 100));
71 qq|SELECT dunning_ar_amount_fee, dunning_ar_amount_interest, dunning_ar
73 ($form->{AR_amount_fee}, $form->{AR_amount_interest}, $form->{AR}) = selectrow_query($form, $dbh, $query);
77 $main::lxdebug->leave_sub();
81 $main::lxdebug->enter_sub();
83 my ($self, $myconfig, $form) = @_;
86 my $dbh = $form->dbconnect_noauto($myconfig);
90 for my $i (1 .. $form->{rowcount}) {
91 $form->{"fee_$i"} = $form->parse_amount($myconfig, $form->{"fee_$i"}) * 1;
92 $form->{"interest_rate_$i"} = $form->parse_amount($myconfig, $form->{"interest_rate_$i"}) / 100;
94 if (($form->{"dunning_level_$i"} ne "") &&
95 ($form->{"dunning_description_$i"} ne "")) {
96 @values = (conv_i($form->{"dunning_level_$i"}), $form->{"dunning_description_$i"},
97 $form->{"email_subject_$i"}, $form->{"email_body_$i"},
98 $form->{"template_$i"}, $form->{"fee_$i"}, $form->{"interest_rate_$i"},
99 $form->{"active_$i"} ? 't' : 'f', $form->{"auto_$i"} ? 't' : 'f', $form->{"email_$i"} ? 't' : 'f',
100 $form->{"email_attachment_$i"} ? 't' : 'f', conv_i($form->{"payment_terms_$i"}), conv_i($form->{"terms_$i"}),
101 $form->{"create_invoices_for_fees_$i"} ? 't' : 'f');
102 if ($form->{"id_$i"}) {
104 qq|UPDATE dunning_config SET
105 dunning_level = ?, dunning_description = ?,
106 email_subject = ?, email_body = ?,
107 template = ?, fee = ?, interest_rate = ?,
108 active = ?, auto = ?, email = ?,
109 email_attachment = ?, payment_terms = ?, terms = ?,
110 create_invoices_for_fees = ?
112 push(@values, conv_i($form->{"id_$i"}));
115 qq|INSERT INTO dunning_config
116 (dunning_level, dunning_description, email_subject, email_body,
117 template, fee, interest_rate, active, auto, email,
118 email_attachment, payment_terms, terms, create_invoices_for_fees)
119 VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)|;
121 do_query($form, $dbh, $query, @values);
124 if (($form->{"dunning_description_$i"} eq "") && ($form->{"id_$i"})) {
125 $query = qq|DELETE FROM dunning_config WHERE id = ?|;
126 do_query($form, $dbh, $query, $form->{"id_$i"});
130 $query = qq|UPDATE defaults SET dunning_ar_amount_fee = ?, dunning_ar_amount_interest = ?, dunning_ar = ?|;
131 @values = (conv_i($form->{AR_amount_fee}), conv_i($form->{AR_amount_interest}), conv_i($form->{AR}));
132 do_query($form, $dbh, $query, @values);
137 $main::lxdebug->leave_sub();
140 sub create_invoice_for_fees {
141 $main::lxdebug->enter_sub();
143 my ($self, $myconfig, $form, $dbh, $dunning_id) = @_;
145 my ($query, @values, $sth, $ref);
147 $query = qq|SELECT dcfg.create_invoices_for_fees
149 LEFT JOIN dunning_config dcfg ON (d.dunning_config_id = dcfg.id)
150 WHERE d.dunning_id = ?|;
151 my ($create_invoices_for_fees) = selectrow_query($form, $dbh, $query, $dunning_id);
153 if (!$create_invoices_for_fees) {
154 $main::lxdebug->leave_sub();
158 $query = qq|SELECT dunning_ar_amount_fee, dunning_ar_amount_interest, dunning_ar FROM defaults|;
159 ($form->{AR_amount_fee}, $form->{AR_amount_interest}, $form->{AR}) = selectrow_query($form, $dbh, $query);
165 SELECT MAX(d_fee.fee)
167 WHERE (d_fee.trans_id = d.trans_id)
168 AND (d_fee.dunning_id <> ?)
169 AND NOT (d_fee.fee_interest_ar_id ISNULL)
174 SELECT MAX(d_interest.interest)
175 FROM dunning d_interest
176 WHERE (d_interest.trans_id = d.trans_id)
177 AND (d_interest.dunning_id <> ?)
178 AND NOT (d_interest.fee_interest_ar_id ISNULL)
180 AS max_previous_interest
182 WHERE dunning_id = ?|;
183 @values = ($dunning_id, $dunning_id, $dunning_id);
184 $sth = prepare_execute_query($form, $dbh, $query, @values);
186 my ($fee_remaining, $interest_remaining) = (0, 0);
187 my ($fee_total, $interest_total) = (0, 0);
189 while (my $ref = $sth->fetchrow_hashref()) {
190 $fee_remaining += $form->round_amount($ref->{fee}, 2);
191 $fee_remaining -= $form->round_amount($ref->{max_previous_fee}, 2);
192 $fee_total += $form->round_amount($ref->{fee}, 2);
193 $interest_remaining += $form->round_amount($ref->{interest}, 2);
194 $interest_remaining -= $form->round_amount($ref->{max_previous_interest}, 2);
195 $interest_total += $form->round_amount($ref->{interest}, 2);
200 my $amount = $fee_remaining + $interest_remaining;
203 $main::lxdebug->leave_sub();
207 my ($ar_id) = selectrow_query($form, $dbh, qq|SELECT nextval('glid')|);
208 my $curr = $form->get_default_currency($myconfig);
209 my $trans_number = SL::TransNumber->new(type => 'invoice', dbh => $dbh);
212 qq|INSERT INTO ar (id, invnumber, transdate, gldate, customer_id,
213 taxincluded, amount, netamount, paid, duedate,
214 invoice, currency_id, taxzone_id, notes,
219 current_date, -- transdate
220 current_date, -- gldate
222 (SELECT ar.customer_id
224 LEFT JOIN ar ON (dn.trans_id = ar.id)
225 WHERE dn.dunning_id = ?
232 (SELECT duedate FROM dunning WHERE dunning_id = ? LIMIT 1),
234 (SELECT id FROM currencies WHERE name = ?), -- curr
236 (SELECT taxzone_id FROM customer WHERE id =
237 (SELECT ar.customer_id
239 LEFT JOIN ar ON (dn.trans_id = ar.id)
240 WHERE dn.dunning_id = ?
245 (SELECT id FROM employee WHERE login = ?)
247 @values = ($ar_id, # id
248 $trans_number->create_unique, # invnumber
249 $dunning_id, # customer_id
252 $dunning_id, # duedate
253 $curr, # default currency
254 $dunning_id, # taxzone_id
255 sprintf($main::locale->text('Automatically created invoice for fee and interest for dunning %s'), $dunning_id), # notes
256 $::myconfig{login}); # employee_id
257 do_query($form, $dbh, $query, @values);
260 qq|INSERT INTO acc_trans (trans_id, chart_id, amount, transdate, gldate, taxkey, tax_id, chart_link)
261 VALUES (?, ?, ?, current_date, current_date, 0,
262 (SELECT id FROM tax WHERE (taxkey = 0) AND (rate = 0)),
263 (SELECT link FROM chart WHERE id = ?))|;
264 $sth = prepare_query($form, $dbh, $query);
266 @values = ($ar_id, conv_i($form->{AR_amount_fee}), $fee_remaining, conv_i($form->{AR_amount_fee}));
267 do_statement($form, $sth, $query, @values);
269 if ($interest_remaining) {
270 @values = ($ar_id, conv_i($form->{AR_amount_interest}), $interest_remaining, conv_i($form->{AR_amount_interest}));
271 do_statement($form, $sth, $query, @values);
274 @values = ($ar_id, conv_i($form->{AR}), -1 * $amount, conv_i($form->{AR}));
275 do_statement($form, $sth, $query, @values);
279 $query = qq|UPDATE dunning SET fee_interest_ar_id = ? WHERE dunning_id = ?|;
280 do_query($form, $dbh, $query, $ar_id, $dunning_id);
282 $main::lxdebug->leave_sub();
286 $main::lxdebug->enter_sub();
288 my ($self, $myconfig, $form, $rows) = @_;
289 # connect to database
290 my $dbh = $form->dbconnect_noauto($myconfig);
292 my ($query, @values);
294 my ($dunning_id) = selectrow_query($form, $dbh, qq|SELECT nextval('id')|);
296 my $q_update_ar = qq|UPDATE ar SET dunning_config_id = ? WHERE id = ?|;
297 my $h_update_ar = prepare_query($form, $dbh, $q_update_ar);
299 my $q_insert_dunning =
300 qq|INSERT INTO dunning (dunning_id, dunning_config_id, dunning_level, trans_id,
301 fee, interest, transdate, duedate)
303 (SELECT dunning_level FROM dunning_config WHERE id = ?),
307 WHERE dunning_level <= (SELECT dunning_level FROM dunning_config WHERE id = ?)),
308 (SELECT (amount - paid) * (current_date - duedate) FROM ar WHERE id = ?)
309 * (SELECT interest_rate FROM dunning_config WHERE id = ?)
312 current_date + (SELECT payment_terms FROM dunning_config WHERE id = ?))|;
313 my $h_insert_dunning = prepare_query($form, $dbh, $q_insert_dunning);
316 my ($next_dunning_config_id, $customer_id);
319 foreach my $row (@{ $rows }) {
320 push @invoice_ids, $row->{invoice_id};
321 $next_dunning_config_id = $row->{next_dunning_config_id};
322 $customer_id = $row->{customer_id};
324 @values = ($row->{next_dunning_config_id}, $row->{invoice_id});
325 do_statement($form, $h_update_ar, $q_update_ar, @values);
327 $send_email |= $row->{email};
329 my $next_config_id = conv_i($row->{next_dunning_config_id});
330 my $invoice_id = conv_i($row->{invoice_id});
332 @values = ($dunning_id, $next_config_id, $next_config_id,
333 $invoice_id, $next_config_id, $invoice_id,
334 $next_config_id, $next_config_id);
335 do_statement($form, $h_insert_dunning, $q_insert_dunning, @values);
338 $h_update_ar->finish();
339 $h_insert_dunning->finish();
341 $form->{DUNNING_PDFS_EMAIL} = [];
343 $form->{dunning_id} = $dunning_id;
345 $self->create_invoice_for_fees($myconfig, $form, $dbh, $dunning_id);
347 $self->print_invoice_for_fees($myconfig, $form, $dunning_id, $dbh);
348 $self->print_dunning($myconfig, $form, $dunning_id, $dbh);
352 $self->send_email($myconfig, $form, $dunning_id, $dbh);
358 $main::lxdebug->leave_sub();
362 $main::lxdebug->enter_sub();
364 my ($self, $myconfig, $form, $dunning_id, $dbh) = @_;
368 dcfg.email_body, dcfg.email_subject, dcfg.email_attachment,
372 LEFT JOIN dunning_config dcfg ON (d.dunning_config_id = dcfg.id)
373 LEFT JOIN ar ON (d.trans_id = ar.id)
374 LEFT JOIN customer c ON (ar.customer_id = c.id)
375 WHERE (d.dunning_id = ?)
377 my $ref = selectfirst_hashref_query($form, $dbh, $query, $dunning_id);
379 if (!$ref || !$ref->{recipient} || !$myconfig->{email}) {
380 $main::lxdebug->leave_sub();
384 my $template = SL::Template::create(type => 'PlainText', form => $form, myconfig => $myconfig);
385 my $mail = Mailer->new();
386 $mail->{from} = $myconfig->{email};
387 $mail->{to} = $ref->{recipient};
388 $mail->{subject} = $template->parse_block($ref->{email_subject});
389 $mail->{message} = $template->parse_block($ref->{email_body});
391 $mail->{message} .= $form->create_email_signature();
393 $mail->{message} =~ s/\r\n/\n/g;
395 if ($ref->{email_attachment} && @{ $form->{DUNNING_PDFS_EMAIL} }) {
396 $mail->{attachments} = $form->{DUNNING_PDFS_EMAIL};
401 $main::lxdebug->leave_sub();
404 sub set_template_options {
405 $main::lxdebug->enter_sub();
407 my ($self, $myconfig, $form) = @_;
409 my $defaults = SL::DB::Default->get;
410 $form->error($::locale->text('No print templates have been created for this client yet. Please do so in the client configuration.')) if !$defaults->templates;
411 $form->{templates} = $defaults->templates;
412 $form->{language} = $form->get_template_language($myconfig);
413 $form->{printer_code} = $form->get_printer_code($myconfig);
415 if ($form->{language} ne "") {
416 $form->{language} = "_" . $form->{language};
419 if ($form->{printer_code} ne "") {
420 $form->{printer_code} = "_" . $form->{printer_code};
423 my $extension = 'html';
424 if ($form->{format} eq 'postscript') {
425 $form->{postscript} = 1;
428 } elsif ($form->{"format"} =~ /pdf/) {
430 $extension = $form->{'format'} =~ m/opendocument/i ? 'odt' : 'tex';
432 } elsif ($form->{"format"} =~ /opendocument/) {
433 $form->{opendocument} = 1;
435 } elsif ($form->{"format"} =~ /excel/) {
441 # search for the template
443 push @template_files, "$form->{formname}_email$form->{language}$form->{printer_code}.$extension" if $form->{media} eq 'email';
444 push @template_files, "$form->{formname}$form->{language}$form->{printer_code}.$extension";
445 push @template_files, "$form->{formname}.$extension";
446 push @template_files, "default.$extension";
449 for my $filename (@template_files) {
450 if (-f ($defaults->templates . "/$filename")) {
451 $form->{IN} = $filename;
456 if (!defined $form->{IN}) {
457 $::form->error($::locale->text('Cannot find matching template for this print request. Please contact your template maintainer. I tried these: #1.', join ', ', map { "'$_'"} @template_files));
460 # prepare meta information for template introspection
461 $form->{template_meta} = {
462 formname => $form->{formname},
463 language => SL::DB::Manager::Language->find_by_or_create(id => $form->{language_id}),
464 format => $form->{format},
465 media => $form->{media},
466 extension => $extension,
467 printer => SL::DB::Manager::Printer->find_by_or_create(id => $form->{printer_id}),
468 today => DateTime->today,
471 $main::lxdebug->leave_sub();
476 $main::lxdebug->enter_sub();
478 my ($self, $myconfig, $form) = @_;
480 # connect to database
481 my $dbh = $form->dbconnect($myconfig);
486 $form->{customer_id} = $1 if ($form->{customer} =~ /--(\d+)$/);
488 if ($form->{customer_id}) {
489 $where .= qq| AND (a.customer_id = ?)|;
490 push(@values, $form->{customer_id});
492 } elsif ($form->{customer}) {
493 $where .= qq| AND (ct.name ILIKE ?)|;
494 push(@values, '%' . $form->{customer} . '%');
498 "ordnumber" => "a.ordnumber",
499 "invnumber" => "a.invnumber",
500 "notes" => "a.notes",
501 "country" => "ct.country",
503 foreach my $key (keys(%columns)) {
504 next unless ($form->{$key});
505 $where .= qq| AND $columns{$key} ILIKE ?|;
506 push(@values, '%' . $form->{$key} . '%');
509 if ($form->{dunning_level}) {
510 $where .= qq| AND nextcfg.id = ?|;
511 push(@values, conv_i($form->{dunning_level}));
514 $form->{minamount} = $form->parse_amount($myconfig,$form->{minamount});
515 if ($form->{minamount}) {
516 $where .= qq| AND ((a.amount - a.paid) > ?) |;
517 push(@values, $form->{minamount});
523 WHERE dunning_level = (SELECT MAX(dunning_level) FROM dunning_config)|;
524 my ($id_for_max_dunning_level) = selectrow_query($form, $dbh, $query);
528 a.id, a.ordnumber, a.transdate, a.invnumber, a.amount, a.language_id,
529 ct.name AS customername, a.customer_id, a.duedate,
530 a.amount - a.paid AS open_amount,
532 cfg.dunning_description, cfg.dunning_level,
534 d.transdate AS dunning_date, d.duedate AS dunning_duedate,
537 a.duedate + cfg.terms - current_date AS nextlevel,
538 current_date - COALESCE(d.duedate, a.duedate) AS pastdue,
539 current_date + cfg.payment_terms AS next_duedate,
541 nextcfg.dunning_description AS next_dunning_description,
542 nextcfg.id AS next_dunning_config_id,
543 nextcfg.terms, nextcfg.active, nextcfg.email
547 LEFT JOIN customer ct ON (a.customer_id = ct.id)
548 LEFT JOIN dunning_config cfg ON (a.dunning_config_id = cfg.id)
549 LEFT JOIN dunning_config nextcfg ON
554 WHERE dunning_level >
555 COALESCE((SELECT dunning_level
557 WHERE id = a.dunning_config_id
558 ORDER BY dunning_level DESC
561 ORDER BY dunning_level ASC
564 LEFT JOIN dunning d ON (d.id = (
567 WHERE (d2.trans_id = a.id)
568 AND (d2.dunning_level = cfg.dunning_level)
571 WHERE (a.paid < a.amount)
572 AND (a.duedate < current_date)
576 ORDER BY a.id, transdate, duedate, name|;
577 my $sth = prepare_execute_query($form, $dbh, $query, $id_for_max_dunning_level, @values);
579 $form->{DUNNINGS} = [];
581 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
582 next if ($ref->{pastdue} < $ref->{terms});
584 $ref->{interest} = $form->round_amount($ref->{interest}, 2);
585 push(@{ $form->{DUNNINGS} }, $ref);
590 $query = qq|SELECT id, dunning_description FROM dunning_config ORDER BY dunning_level|;
591 $form->{DUNNING_CONFIG} = selectall_hashref_query($form, $dbh, $query);
594 $main::lxdebug->leave_sub();
599 $main::lxdebug->enter_sub();
601 my ($self, $myconfig, $form) = @_;
603 # connect to database
604 my $dbh = $form->dbconnect($myconfig);
606 my $where = qq| WHERE (da.trans_id = a.id)|;
610 if ($form->{customer_id}) {
611 $where .= qq| AND (a.customer_id = ?)|;
612 push(@values, $form->{customer_id});
614 } elsif ($form->{customer}) {
615 $where .= qq| AND (ct.name ILIKE ?)|;
616 push(@values, '%' . $form->{customer} . '%');
620 "ordnumber" => "a.ordnumber",
621 "invnumber" => "a.invnumber",
622 "notes" => "a.notes",
624 foreach my $key (keys(%columns)) {
625 next unless ($form->{$key});
626 $where .= qq| AND $columns{$key} ILIKE ?|;
627 push(@values, '%' . $form->{$key} . '%');
630 if ($form->{dunning_level}) {
631 $where .= qq| AND a.dunning_config_id = ?|;
632 push(@values, conv_i($form->{dunning_level}));
635 if ($form->{department_id}) {
636 $where .= qq| AND a.department_id = ?|;
637 push @values, conv_i($form->{department_id});
640 $form->{minamount} = $form->parse_amount($myconfig, $form->{minamount});
641 if ($form->{minamount}) {
642 $where .= qq| AND ((a.amount - a.paid) > ?) |;
643 push(@values, $form->{minamount});
646 if (!$form->{showold}) {
647 $where .= qq| AND (a.amount > a.paid) AND (da.dunning_config_id = a.dunning_config_id) |;
650 if ($form->{transdatefrom}) {
651 $where .= qq| AND a.transdate >= ?|;
652 push(@values, $form->{transdatefrom});
654 if ($form->{transdateto}) {
655 $where .= qq| AND a.transdate <= ?|;
656 push(@values, $form->{transdateto});
658 if ($form->{dunningfrom}) {
659 $where .= qq| AND da.transdate >= ?|;
660 push(@values, $form->{dunningfrom});
662 if ($form->{dunningto}) {
663 $where .= qq| AND da.transdate >= ?|;
664 push(@values, $form->{dunningto});
667 if ($form->{salesman_id}) {
668 $where .= qq| AND a.salesman_id = ?|;
669 push(@values, conv_i($form->{salesman_id}));
673 'dunning_description' => [ qw(dn.dunning_description customername invnumber) ],
674 'customername' => [ qw(customername invnumber) ],
675 'invnumber' => [ qw(a.invnumber) ],
676 'transdate' => [ qw(a.transdate a.invnumber) ],
677 'duedate' => [ qw(a.duedate a.invnumber) ],
678 'dunning_date' => [ qw(dunning_date a.invnumber) ],
679 'dunning_duedate' => [ qw(dunning_duedate a.invnumber) ],
680 'salesman' => [ qw(salesman) ],
683 my $sortdir = !defined $form->{sortdir} ? 'ASC' : $form->{sortdir} ? 'ASC' : 'DESC';
684 my $sortkey = $sort_columns{$form->{sort}} ? $form->{sort} : 'customername';
685 my $sortorder = join ', ', map { "$_ $sortdir" } @{ $sort_columns{$sortkey} };
688 qq|SELECT a.id, a.ordnumber, a.invoice, a.transdate, a.invnumber, a.amount, a.language_id,
689 ct.name AS customername, ct.id AS customer_id, a.duedate, da.fee,
690 da.interest, dn.dunning_description, da.transdate AS dunning_date,
691 da.duedate AS dunning_duedate, da.dunning_id, da.dunning_config_id,
694 JOIN customer ct ON (a.customer_id = ct.id)
695 LEFT JOIN employee e2 ON (a.salesman_id = e2.id), dunning da
696 LEFT JOIN dunning_config dn ON (da.dunning_config_id = dn.id)
698 ORDER BY $sortorder|;
700 $form->{DUNNINGS} = selectall_hashref_query($form, $dbh, $query, @values);
702 foreach my $ref (@{ $form->{DUNNINGS} }) {
703 map { $ref->{$_} = $form->format_amount($myconfig, $ref->{$_}, 2)} qw(amount fee interest);
707 $main::lxdebug->leave_sub();
712 $main::lxdebug->enter_sub();
714 my ($self, $myconfig, $form, $copies) = @_;
716 # Don't allow access outside of $spool.
717 map { $_ =~ s|.*/||; } @{ $form->{DUNNING_PDFS} };
720 $copies = 1 unless $copies;
721 my $spool = $::lx_office_conf{paths}->{spool};
722 my $inputfiles = join " ", map { "$spool/$_ " x $copies } @{ $form->{DUNNING_PDFS} };
723 my $dunning_id = $form->{dunning_id};
725 $dunning_id =~ s|[^\d]||g;
727 my $in = IO::File->new($::lx_office_conf{applications}->{ghostscript} . " -dBATCH -dNOPAUSE -q -sDEVICE=pdfwrite -sOutputFile=- $inputfiles |");
728 $form->error($main::locale->text('Could not spawn ghostscript.')) unless $in;
730 if ($form->{media} eq 'printer') {
731 $form->get_printer_code($myconfig);
733 if ($form->{printer_command}) {
734 $out = IO::File->new("| $form->{printer_command}");
737 $::locale->with_raw_io($out, sub { $out->print($_) while <$in> });
739 $form->error($main::locale->text('Could not spawn the printer command.')) unless $out;
742 my $dunning_filename = $form->get_formname_translation('dunning');
743 print qq|Content-Type: Application/PDF\n| .
744 qq|Content-Disposition: attachment; filename="${dunning_filename}_${dunning_id}.pdf"\n\n|;
746 $::locale->with_raw_io(\*STDOUT, sub { print while <$in> });
751 map { unlink("$spool/$_") } @{ $form->{DUNNING_PDFS} };
753 $main::lxdebug->leave_sub();
757 $main::lxdebug->enter_sub();
759 my ($self, $myconfig, $form, $dunning_id, $provided_dbh) = @_;
761 # connect to database
762 my $dbh = $provided_dbh ? $provided_dbh : $form->dbconnect_noauto($myconfig);
764 $dunning_id =~ s|[^\d]||g;
766 my ($language_tc, $output_numberformat, $output_dateformat, $output_longdates);
767 if ($form->{"language_id"}) {
768 ($language_tc, $output_numberformat, $output_dateformat, $output_longdates) =
769 AM->get_language_details($myconfig, $form, $form->{language_id});
771 $output_dateformat = $myconfig->{dateformat};
772 $output_numberformat = $myconfig->{numberformat};
773 $output_longdates = 1;
779 da.transdate AS dunning_date,
780 da.duedate AS dunning_duedate,
782 dcfg.template AS formname,
783 dcfg.email_subject, dcfg.email_body, dcfg.email_attachment,
785 ar.transdate, ar.duedate, ar.customer_id,
786 ar.invnumber, ar.ordnumber, ar.cp_id,
787 ar.amount, ar.netamount, ar.paid,
788 (SELECT cu.name FROM currencies cu WHERE cu.id=ar.currency_id) AS curr,
789 ar.amount - ar.paid AS open_amount,
790 ar.amount - ar.paid + da.fee + da.interest AS linetotal
793 LEFT JOIN dunning_config dcfg ON (dcfg.id = da.dunning_config_id)
794 LEFT JOIN ar ON (ar.id = da.trans_id)
795 WHERE (da.dunning_id = ?)|;
797 my $sth = prepare_execute_query($form, $dbh, $query, $dunning_id);
799 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
801 $form->{TEMPLATE_ARRAYS} = {};
802 map({ $form->{TEMPLATE_ARRAYS}->{"dn_$_"} = []; } keys(%{$ref}));
805 map { $ref->{$_} = $form->format_amount($myconfig, $ref->{$_}, 2) } qw(amount netamount paid open_amount fee interest linetotal);
806 map { $form->{$_} = $ref->{$_} } keys %$ref;
807 map { push @{ $form->{TEMPLATE_ARRAYS}->{"dn_$_"} }, $ref->{$_} } keys %$ref;
813 c.id AS customer_id, c.name, c.street, c.zipcode, c.city,
814 c.country, c.department_1, c.department_2, c.email, c.customernumber,
815 c.greeting, c.contact, c.phone, c.fax, c.homepage,
816 c.email, c.taxincluded, c.business_id, c.taxnumber, c.iban,
817 c,ustid, e.name as salesman_name,
820 LEFT JOIN ar ON (d.trans_id = ar.id)
821 LEFT JOIN customer c ON (ar.customer_id = c.id)
822 LEFT JOIN contacts co ON (ar.cp_id = co.cp_id)
823 LEFT JOIN employee e ON (ar.salesman_id = e.id)
824 WHERE (d.dunning_id = ?)
826 my $ref = selectfirst_hashref_query($form, $dbh, $query, $dunning_id);
827 map { $form->{$_} = $ref->{$_} } keys %{ $ref };
831 cfg.interest_rate, cfg.template AS formname,
832 cfg.email_subject, cfg.email_body, cfg.email_attachment,
833 d.transdate AS dunning_date,
836 WHERE dunning_id = ?)
838 (SELECT SUM(interest)
840 WHERE dunning_id = ?)
842 (SELECT SUM(amount) - SUM(paid)
847 WHERE dunning_id = ?))
850 LEFT JOIN dunning_config cfg ON (d.dunning_config_id = cfg.id)
851 WHERE d.dunning_id = ?
853 $ref = selectfirst_hashref_query($form, $dbh, $query, $dunning_id, $dunning_id, $dunning_id, $dunning_id);
854 map { $form->{$_} = $ref->{$_} } keys %{ $ref };
856 $form->{interest_rate} = $form->format_amount($myconfig, $ref->{interest_rate} * 100);
857 $form->{fee} = $form->format_amount($myconfig, $ref->{fee}, 2);
858 $form->{total_interest} = $form->format_amount($myconfig, $form->round_amount($ref->{total_interest}, 2), 2);
859 $form->{total_open_amount} = $form->format_amount($myconfig, $form->round_amount($ref->{total_open_amount}, 2), 2);
860 $form->{total_amount} = $form->format_amount($myconfig, $form->round_amount($ref->{fee} + $ref->{total_interest} + $ref->{total_open_amount}, 2), 2);
862 $::form->format_dates($output_dateformat, $output_longdates,
863 qw(dn_dunning_date dn_dunning_duedate dn_transdate dn_duedate
864 dunning_date dunning_duedate transdate duedate)
866 $::form->reformat_numbers($output_numberformat, 2, qw(
867 dn_amount dn_netamount dn_paid dn_open_amount dn_fee dn_interest dn_linetotal
868 amount netamount paid open_amount fee interest linetotal
869 total_interest total_open_interest total_amount total_open_amount
871 $::form->reformat_numbers($output_numberformat, undef, qw(interest_rate));
873 $self->set_customer_cvars($myconfig, $form);
874 $self->set_template_options($myconfig, $form);
876 my $filename = "dunning_${dunning_id}_" . Common::unique_id() . ".pdf";
877 my $spool = $::lx_office_conf{paths}->{spool};
878 $form->{OUT} = "${spool}/$filename";
879 $form->{keep_tmpfile} = 1;
881 delete $form->{tmpfile};
883 push @{ $form->{DUNNING_PDFS} }, $filename;
884 push @{ $form->{DUNNING_PDFS_EMAIL} }, { 'filename' => "${spool}/$filename",
885 'name' => $form->get_formname_translation('dunning') . "_${dunning_id}.pdf" };
887 $form->parse_template($myconfig);
889 $dbh->disconnect() unless $provided_dbh;
891 $main::lxdebug->leave_sub();
894 sub print_invoice_for_fees {
895 $main::lxdebug->enter_sub();
897 my ($self, $myconfig, $form, $dunning_id, $provided_dbh) = @_;
899 my $dbh = $provided_dbh ? $provided_dbh : $form->dbconnect($myconfig);
901 my ($query, @values, $sth);
905 d.fee_interest_ar_id,
908 LEFT JOIN dunning_config dcfg ON (d.dunning_config_id = dcfg.id)
909 WHERE d.dunning_id = ?|;
910 my ($ar_id, $template) = selectrow_query($form, $dbh, $query, $dunning_id);
913 $main::lxdebug->leave_sub();
917 my $saved_form = save_form();
919 $query = qq|SELECT SUM(fee), SUM(interest) FROM dunning WHERE id = ?|;
920 my ($fee_total, $interest_total) = selectrow_query($form, $dbh, $query, $dunning_id);
924 ar.invnumber, ar.transdate AS invdate, ar.amount, ar.netamount,
925 ar.duedate, ar.notes, ar.notes AS invoicenotes, ar.customer_id,
927 c.name, c.department_1, c.department_2, c.street, c.zipcode, c.city, c.country,
928 c.contact, c.customernumber, c.phone, c.fax, c.email,
929 c.taxnumber, c.greeting
932 LEFT JOIN customer c ON (ar.customer_id = c.id)
934 my $ref = selectfirst_hashref_query($form, $dbh, $query, $ar_id);
935 map { $form->{$_} = $ref->{$_} } keys %{ $ref };
937 $query = qq|SELECT * FROM employee WHERE login = ?|;
938 $ref = selectfirst_hashref_query($form, $dbh, $query, $::myconfig{login});
939 map { $form->{"employee_${_}"} = $ref->{$_} } keys %{ $ref };
941 $query = qq|SELECT * FROM acc_trans WHERE trans_id = ? ORDER BY acc_trans_id ASC|;
942 $sth = prepare_execute_query($form, $dbh, $query, $ar_id);
944 my ($row, $fee, $interest) = (0, 0, 0);
946 while ($ref = $sth->fetchrow_hashref()) {
947 next if ($ref->{amount} < 0);
952 $fee = $ref->{amount};
954 $interest = $ref->{amount};
958 $form->{fee} = $form->round_amount($fee, 2);
959 $form->{interest} = $form->round_amount($interest, 2);
960 $form->{invamount} = $form->round_amount($fee + $interest, 2);
961 $form->{dunning_id} = $dunning_id;
962 $form->{formname} = "${template}_invoice";
964 map { $form->{$_} = $form->format_amount($myconfig, $form->{$_}, 2) } qw(fee interest invamount);
966 $self->set_customer_cvars($myconfig, $form);
967 $self->set_template_options($myconfig, $form);
969 my $filename = Common::unique_id() . "dunning_invoice_${dunning_id}.pdf";
971 my $spool = $::lx_office_conf{paths}->{spool};
972 $form->{OUT} = "$spool/$filename";
973 $form->{keep_tmpfile} = 1;
974 delete $form->{tmpfile};
976 map { delete $form->{$_} } grep /^[a-z_]+_\d+$/, keys %{ $form };
978 $form->parse_template($myconfig);
980 restore_form($saved_form);
982 push @{ $form->{DUNNING_PDFS} }, $filename;
983 push @{ $form->{DUNNING_PDFS_EMAIL} }, { 'filename' => "${spool}/$filename",
984 'name' => "dunning_invoice_${dunning_id}.pdf" };
986 $dbh->disconnect() unless $provided_dbh;
988 $main::lxdebug->leave_sub();
991 sub set_customer_cvars {
992 my ($self, $myconfig, $form) = @_;
994 my $custom_variables = CVar->get_custom_variables(dbh => $form->get_standard_dbh,
996 trans_id => $form->{customer_id});
997 map { $form->{"vc_cvar_$_->{name}"} = $_->{value} } @{ $custom_variables };
999 $form->{cp_greeting} = GenericTranslations->get(dbh => $form->get_standard_dbh,
1000 translation_type => 'greetings::' . ($form->{cp_gender} eq 'f' ? 'female' : 'male'),
1001 language_id => $form->{language_id},
1002 allow_fallback => 1);