1 package SL::BackgroundJob::SelfTest::Transactions;
5 use parent qw(SL::BackgroundJob::SelfTest::Base);
9 use Rose::Object::MakeMethods::Generic (
10 scalar => [ qw(dbh fromdate todate) ],
18 $self->tester->plan(tests => 34);
20 $self->check_konten_mit_saldo_nicht_in_guv;
21 $self->check_bilanzkonten_mit_pos_eur;
22 $self->check_balanced_individual_transactions;
23 $self->check_verwaiste_acc_trans_eintraege;
24 $self->check_verwaiste_invoice_eintraege;
25 $self->check_ar_acc_trans_amount;
26 $self->check_ap_acc_trans_amount;
27 $self->check_netamount_laut_invoice_ar;
28 $self->check_invnumbers_unique;
29 $self->check_summe_stornobuchungen;
32 $self->check_ar_overpayments;
33 $self->check_ap_overpayments;
34 $self->check_paid_stornos;
35 $self->check_stornos_ohne_partner;
36 $self->check_overpayments;
37 $self->check_every_account_with_taxkey;
38 $self->calc_saldenvortraege;
39 $self->check_missing_tax_bookings;
40 $self->check_bank_transactions_overpayments;
41 $self->check_ar_paid_acc_trans;
42 $self->check_ap_paid_acc_trans;
43 $self->check_zero_amount_paid_but_datepaid_exists;
44 $self->check_orphaned_reconciliated_links;
45 $self->check_recommended_client_settings;
46 $self->check_orphaned_bank_transaction_acc_trans_links;
47 $self->check_consistent_itimes;
53 # TODO FIXME calc dates better, unless this is wanted
54 $self->fromdate(DateTime->new(day => 1, month => 1, year => DateTime->today->year));
55 $self->todate($self->fromdate->clone->add(years => 1)->add(days => -1));
56 $self->dbh($::form->get_standard_dbh);
59 sub check_konten_mit_saldo_nicht_in_guv {
63 SELECT c.accno, c.description, c.category, SUM(a.amount) AS Saldo
66 WHERE c.id = a.chart_id
67 and (c.category like 'I' or c.category like 'E')
70 and a.transdate >= ? and a.transdate <= ?
71 GROUP BY c.accno,c.description,c.category,c.pos_bilanz,c.pos_eur
74 my $konten_nicht_in_guv = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
76 my $correct = 0 == scalar grep { $_->{Saldo} } @$konten_nicht_in_guv;
78 $self->tester->ok($correct, "Erfolgskonten mit Saldo nicht in GuV (Saldenvortragskonten können ignoriert werden, sollten aber 0 sein)");
80 for my $konto (@$konten_nicht_in_guv) {
81 $self->tester->diag($konto);
86 sub check_bilanzkonten_mit_pos_eur {
89 my $query = qq|SELECT accno, description FROM chart WHERE (category = 'A' OR category = 'L' OR category = 'Q') AND (pos_eur IS NOT NULL OR pos_eur != 0)|;
91 my $bilanzkonten_mit_pos_eur = selectall_hashref_query($::form, $self->dbh, $query);
92 if (@$bilanzkonten_mit_pos_eur) {
93 $self->tester->ok(0, "Es gibt Bilanzkonten die der GuV/EÜR zugeordnet sind)");
94 $self->tester->diag("$_->{accno} $_->{description}") for @$bilanzkonten_mit_pos_eur;
96 $self->tester->ok(1, "Keine Bilanzkonten in der GuV");
100 sub check_balanced_individual_transactions {
104 select sum(ac.amount) as amount,trans_id,ar.invnumber as ar,ap.invnumber as ap,gl.reference as gl
106 left join ar on (ar.id = ac.trans_id)
107 left join ap on (ap.id = ac.trans_id)
108 left join gl on (gl.id = ac.trans_id)
109 where ac.transdate >= ? AND ac.transdate <= ?
110 group by trans_id,ar.invnumber,ap.invnumber,gl.reference
111 having sum(ac.amount) != 0;|;
113 my $acs = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
115 $self->tester->ok(0, "Es gibt unausgeglichene acc_trans-Transaktionen:");
116 for my $ac (@{ $acs }) {
117 $self->tester->diag("trans_id: $ac->{trans_id}, amount = $ac->{amount}, ar: $ac->{ar} ap: $ac->{ap} gl: $ac->{gl}");
120 $self->tester->ok(1, "Alle acc_trans Transaktionen ergeben in Summe 0, keine unausgeglichenen Transaktionen");
124 sub check_verwaiste_acc_trans_eintraege {
128 select trans_id,amount,accno,description from acc_trans a
129 left join chart c on (c.id = a.chart_id)
130 where trans_id not in (select id from gl union select id from ar union select id from ap order by id)
131 and a.transdate >= ? and a.transdate <= ? ;|;
133 my $verwaiste_acs = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
134 if (@$verwaiste_acs) {
135 $self->tester->ok(0, "Es gibt verwaiste acc-trans Einträge! (wo ar/ap/gl-Eintrag fehlt)");
136 $self->tester->diag($_) for @$verwaiste_acs;
138 $self->tester->ok(1, "Keine verwaisten acc-trans Einträge (wo ar/ap/gl-Eintrag fehlt)");
142 sub check_verwaiste_invoice_eintraege {
143 # this check is always run for all invoice entries in the entire database
146 select * from invoice i
147 where trans_id not in (select id from ar WHERE ar.transdate >=? AND ar.transdate <=?
149 select id from ap WHERE ap.transdate >= ? and ap.transdate <= ?)
150 AND i.transdate >=? AND i.transdate <=?|;
152 my $verwaiste_invoice = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate,
153 $self->fromdate, $self->todate, $self->fromdate, $self->todate);
156 if (@$verwaiste_invoice) {
157 $self->tester->ok(0, "Es gibt verwaiste invoice Einträge! (wo ar/ap-Eintrag fehlt)");
158 for my $invoice ( @{ $verwaiste_invoice }) {
159 $self->tester->diag("invoice: id: $invoice->{id} trans_id: $invoice->{trans_id} description: $invoice->{description} itime: $invoice->{itime}");
162 $self->tester->ok(1, "Keine verwaisten invoice Einträge (wo ar/ap-Eintrag fehlt)"); }
165 sub check_netamount_laut_invoice_ar {
168 select sum(round(cast(i.qty*(i.fxsellprice * (1-i.discount)) as numeric), 2))
170 left join ar a on (a.id = i.trans_id)
171 where a.transdate >= ? and a.transdate <= ?;|;
172 my ($netamount_laut_invoice) = selectfirst_array_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
174 $query = qq| select sum(netamount) from ar where transdate >= ? and transdate <= ? AND invoice; |;
175 my ($netamount_laut_ar) = selectfirst_array_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
177 # should be enough to get a diff below 1. We have currently the following issues:
178 # verkaufsbericht berücksichtigt keinen rabatt
179 # fxsellprice ist mit mwst-inklusive
180 my $correct = abs($netamount_laut_invoice - $netamount_laut_ar) < 1;
182 $self->tester->ok($correct, "Summe laut Verkaufsbericht sollte gleich Summe aus Verkauf -> Berichte -> Rechnungen sein");
184 $self->tester->diag("Netto-Summe laut Verkaufsbericht (invoice): $netamount_laut_invoice");
185 $self->tester->diag("Netto-Summe laut Verkauf -> Berichte -> Rechnungen: $netamount_laut_ar");
189 sub check_invnumbers_unique {
192 my $query = qq| select invnumber,count(invnumber) as count from ar
193 where transdate >= ? and transdate <= ?
195 having count(invnumber) > 1; |;
196 my $non_unique_invnumbers = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
198 if (@$non_unique_invnumbers) {
199 $self->tester->ok(0, "Es gibt doppelte Rechnungsnummern");
200 for my $invnumber (@{ $non_unique_invnumbers }) {
201 $self->tester->diag("invnumber: $invnumber->{invnumber} $invnumber->{count}x");
204 $self->tester->ok(1, "Alle Rechnungsnummern sind eindeutig");
208 sub check_summe_stornobuchungen {
213 foreach my $table (qw(ar ap)) {
214 # check invoices canceled (stornoed) in consideration period (corresponding stornos do not have to be in this period)
216 SELECT sum(amount) FROM $table WHERE id IN (
217 SELECT id FROM $table WHERE storno IS TRUE AND storno_id IS NULL AND transdate >= ? AND transdate <= ?
219 SELECT id FROM $table WHERE storno IS TRUE AND storno_id IS NOT NULL AND storno_id IN
220 (SELECT id FROM $table WHERE storno IS TRUE AND storno_id IS NULL AND transdate >= ? AND transdate <= ?)
222 ($sums_canceled{$table}) = selectfirst_array_query($::form, $self->dbh, $query, $self->fromdate, $self->todate, $self->fromdate, $self->todate);
224 # check storno invoices in consideration period (corresponding canceled (stornoed) invoices do not have to be in this period)
226 SELECT sum(amount) FROM $table WHERE id IN (
227 SELECT storno_id FROM $table WHERE storno IS TRUE AND storno_id IS NOT NULL AND transdate >= ? AND transdate <= ?
229 SELECT id FROM $table WHERE storno IS TRUE AND storno_id IS NOT NULL AND transdate >= ? AND transdate <= ?
231 ($sums_storno{$table}) = selectfirst_array_query($::form, $self->dbh, $query, $self->fromdate, $self->todate, $self->fromdate, $self->todate);
233 my $text_rg = ($table eq 'ar') ? 'Verkaufsrechnungen' : 'Einkaufsrechnungen';
235 $self->tester->ok($sums_canceled{$table} == 0, "Summe aller $text_rg (stornos + stornierte) soll 0 sein (für stornierte Rechnungen)");
236 $self->tester->ok($sums_storno {$table} == 0, "Summe aller $text_rg (stornos + stornierte) soll 0 sein (für Storno-Rechnungen)");
237 $self->tester->diag("Summe $text_rg ($table) (für stornierte Rechnungen) : " . $sums_canceled{$table}) if $sums_canceled{$table} != 0;
238 $self->tester->diag("Summe $text_rg ($table) (für Storno-Rechnungen) : " . $sums_storno {$table}) if $sums_storno {$table} != 0;
246 select invnumber,paid,
247 (select sum(amount) from acc_trans a left join chart c on (c.id = a.chart_id) where trans_id = ar.id and c.link like '%AR_paid%') as accpaid ,
248 paid+(select sum(amount) from acc_trans a left join chart c on (c.id = a.chart_id) where trans_id = ar.id and c.link like '%AR_paid%') as diff
251 (select sum(amount) from acc_trans a left join chart c on (c.id = a.chart_id) where trans_id = ar.id and c.link like '%AR_paid%') is not null
253 AND ar.id in (SELECT id from ar where transdate >= ? and transdate <= ?)
256 my $paid_diffs_ar = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
258 my $errors = scalar grep { $_->{diff} != 0 } @$paid_diffs_ar;
260 $self->tester->ok(!$errors, "Vergleich ar paid mit acc_trans AR_paid");
262 for my $paid_diff_ar (@{ $paid_diffs_ar }) {
263 next if $paid_diff_ar->{diff} == 0;
264 $self->tester->diag("ar invnumber: $paid_diff_ar->{invnumber} : paid: $paid_diff_ar->{paid} acc_paid= $paid_diff_ar->{accpaid} diff: $paid_diff_ar->{diff}");
272 select invnumber,paid,id,
273 (select sum(amount) from acc_trans a left join chart c on (c.id = a.chart_id) where trans_id = ap.id and c.link like '%AP_paid%') as accpaid ,
274 paid-(select sum(amount) from acc_trans a left join chart c on (c.id = a.chart_id) where trans_id = ap.id and c.link like '%AP_paid%') as diff
277 (select sum(amount) from acc_trans a left join chart c on (c.id = a.chart_id) where trans_id = ap.id and c.link like '%AP_paid%') is not null
278 AND ap.id in (SELECT id from ap where transdate >= ? and transdate <= ?)
281 my $paid_diffs_ap = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
283 my $errors = scalar grep { $_->{diff} != 0 } @$paid_diffs_ap;
285 $self->tester->ok(!$errors, "Vergleich ap paid mit acc_trans AP_paid");
286 for my $paid_diff_ap (@{ $paid_diffs_ap }) {
287 next if $paid_diff_ap->{diff} == 0;
288 $self->tester->diag("ap invnumber: $paid_diff_ap->{invnumber} : ID :: ID : $paid_diff_ap->{id} : paid: $paid_diff_ap->{paid} acc_paid= $paid_diff_ap->{accpaid} diff: $paid_diff_ap->{diff}");
292 sub check_ar_overpayments {
296 select invnumber,paid,amount,transdate,c.customernumber,c.name from ar left join customer c on (ar.customer_id = c.id)
297 where abs(paid) > abs(amount)
298 AND transdate >= ? and transdate <= ?
299 order by invnumber;|;
301 my $overpaids_ar = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
303 my $correct = 0 == @$overpaids_ar;
305 $self->tester->ok($correct, "Keine Überzahlungen laut ar.paid");
306 for my $overpaid_ar (@{ $overpaids_ar }) {
307 $self->tester->diag("ar invnumber: $overpaid_ar->{invnumber} : paid: $overpaid_ar->{paid} amount= $overpaid_ar->{amount} transdate = $overpaid_ar->{transdate}");
311 sub check_ap_overpayments {
315 select invnumber,paid,amount,transdate,vc.vendornumber,vc.name from ap left join vendor vc on (ap.vendor_id = vc.id)
316 where abs(paid) > abs(amount)
317 AND transdate >= ? and transdate <= ?
318 order by invnumber;|;
320 my $overpaids_ap = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
322 my $correct = 0 == @$overpaids_ap;
324 $self->tester->ok($correct, "Überzahlungen laut ap.paid:");
325 for my $overpaid_ap (@{ $overpaids_ap }) {
326 $self->tester->diag("ap invnumber: $overpaid_ap->{invnumber} : paid: $overpaid_ap->{paid} amount= $overpaid_ap->{amount} transdate = $overpaid_ap->{transdate}");
330 sub check_paid_stornos {
334 SELECT ar.invnumber,sum(amount - COALESCE((SELECT sum(amount)*-1
335 FROM acc_trans LEFT JOIN chart ON (acc_trans.chart_id=chart.id)
336 WHERE link ilike '%paid%' AND acc_trans.trans_id=ar.id ),0)) as "open"
340 AND (ar.customer_id = customer.id)
341 AND ar.transdate >= ? and ar.transdate <= ?
342 GROUP BY ar.invnumber|;
343 my $paid_stornos = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
345 $self->tester->ok(0 == @$paid_stornos, "Keine bezahlten Stornos");
346 for my $paid_storno (@{ $paid_stornos }) {
347 $self->tester->diag("invnumber: $paid_storno->{invnumber} offen: $paid_storno->{open}");
351 sub check_stornos_ohne_partner {
355 SELECT (SELECT cast ('ar' as text)) as invoice ,ar.id,invnumber,storno,amount,transdate,type,customernumber as cv_number
357 LEFT JOIN customer c on (c.id = ar.customer_id)
358 WHERE storno_id is null AND storno is true AND ar.id not in (SELECT storno_id FROM ar WHERE storno_id is not null AND storno is true)
359 AND ar.transdate >= ? and ar.transdate <= ?
361 SELECT (SELECT cast ('ap' as text)) as invoice,ap.id,invnumber,storno,amount,transdate,type,vendornumber as cv_number
363 LEFT JOIN vendor v on (v.id = ap.vendor_id)
364 WHERE storno_id is null AND storno is true AND ap.id not in (SELECT storno_id FROM ap WHERE storno_id is not null AND storno is true)
365 AND ap.transdate >= ? and ap.transdate <= ?|;
367 my $stornos_ohne_partner = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate,
368 $self->fromdate, $self->todate);
370 $self->tester->ok(@$stornos_ohne_partner == 0, 'Es sollte keine Stornos ohne Partner geben');
371 if (@$stornos_ohne_partner) {
372 $self->tester->diag("Stornos ohne Partner, oder Storno über Jahreswechsel hinaus");
374 my $stornoheader = 0;
375 for my $storno (@{ $stornos_ohne_partner }) {
376 if (!$stornoheader++) {
377 $self->tester->diag(join "\t", keys %$storno);
379 $self->tester->diag(join "\t", map { $storno->{$_} } keys %$storno);
383 sub check_overpayments {
386 # Vergleich ar.paid und das was laut acc_trans bezahlt wurde
387 # "als bezahlt markieren" ohne sauberes Ausbuchen führt zu Differenzen bei offenen Forderungen
388 # Berücksichtigt Zahlungseingänge im Untersuchungszeitraums und
389 # prüft weitere Zahlungen und Buchungen über trans_id (kein Zeitfilter)
393 invnumber,customernumber,name,ar.transdate,ar.datepaid,
395 amount-paid as "open via ar",
396 paid as "paid via ar",
397 coalesce((SELECT sum(amount)*-1 FROM acc_trans
398 WHERE chart_link ilike '%paid%' AND acc_trans.trans_id=ar.id),0) as "paid via acc_trans"
399 FROM ar left join customer c on (c.id = ar.customer_id)
402 AND ar.id in (SELECT trans_id from acc_trans where transdate >= ? AND transdate <= ? AND chart_link ilike '%paid%')|;
404 my $invoices = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
406 my $count_overpayments = scalar grep {
407 $_->{"paid via ar"} != $_->{"paid via acc_trans"}
408 || ( $_->{"amount"} - $_->{"paid via acc_trans"} != $_->{"open via ar"}
409 && $_->{"paid via ar"} != $_->{"paid via acc_trans"} )
412 $self->tester->ok($count_overpayments == 0, 'Vergleich ar.paid und das was laut acc_trans bezahlt wurde');
414 if ($count_overpayments) {
415 for my $invoice (@{ $invoices }) {
416 if ($invoice->{"paid via ar"} != $invoice->{"paid via acc_trans"}) {
417 $self->tester->diag("Rechnung: $invoice->{invnumber}, Kunde $invoice->{name} Nebenbuch-Bezahlwert: (@{[ $invoice->{'paid via ar'} * 1 ]}) != Hauptbuch-Bezahlwert: (@{[ $invoice->{'paid via acc_trans'} * 1 ]}) (at least until transdate!)");
418 if (defined $invoice->{datepaid}) {
419 $self->tester->diag("datepaid = $invoice->{datepaid})");
421 $self->tester->diag("Überzahlung bei Rechnung: $invoice->{invnumber}") if $invoice->{"paid via acc_trans"} > $invoice->{amount};
422 } elsif ( $invoice->{"amount"} - $invoice->{"paid via acc_trans"} != $invoice->{"open via ar"} && $invoice->{"paid via ar"} != $invoice->{"paid via acc_trans"}) {
423 $self->tester->diag("amount - paid_via_acc_trans != open_via_ar");
424 $self->tester->diag("Überzahlung bei Rechnung: $invoice->{invnumber}") if $invoice->{"paid via acc_trans"} > $invoice->{amount};
432 sub calc_saldenvortraege {
435 my $saldenvortragskonto = '9000';
437 # Saldo Saldenvortragskonto 9000 am Jahresanfang
439 select sum(amount) from acc_trans where chart_id = (select id from chart where accno = ?) and transdate <= ?|;
440 my ($saldo_9000_jahresanfang) = selectfirst_array_query($::form, $self->dbh, $query, $saldenvortragskonto, DateTime->new(day => 1, month => 1, year => DateTime->today->year));
441 $self->tester->diag("Saldo 9000 am 01.01.@{[DateTime->today->year]}: @{[ $saldo_9000_jahresanfang * 1 ]} (sollte 0 sein)");
443 # Saldo Saldenvortragskonto 9000 am Jahresende
445 select sum(amount) from acc_trans where chart_id = (select id from chart where accno = ?) and transdate <= ?|;
446 my ($saldo_9000_jahresende) = selectfirst_array_query($::form, $self->dbh, $query, $saldenvortragskonto, DateTime->new(day => 31, month => 12, year => DateTime->today->year));
447 $self->tester->diag("Saldo $saldenvortragskonto am 31.12.@{[DateTime->today->year]}: @{[ $saldo_9000_jahresende * 1 ]} (sollte 0 sein)");
450 sub check_every_account_with_taxkey {
453 my $query = qq|SELECT accno, description FROM chart WHERE id NOT IN (select chart_id from taxkeys)|;
454 my $accounts_without_tk = selectall_hashref_query($::form, $self->dbh, $query);
456 if ( scalar @{ $accounts_without_tk } > 0 ){
457 $self->tester->ok(0, "Folgende Konten haben keinen gültigen Steuerschlüssel:");
459 for my $account_without_tk (@{ $accounts_without_tk } ) {
460 $self->tester->diag("Kontonummer: $account_without_tk->{accno} Beschreibung: $account_without_tk->{description}");
463 $self->tester->ok(1, "Jedes Konto hat einen gültigen Steuerschlüssel!");
467 sub check_ar_acc_trans_amount {
471 select sum(ac.amount) as amount, ar.invnumber,ar.netamount
472 from acc_trans ac left join ar on (ac.trans_id = ar.id)
473 WHERE ac.chart_link like 'AR_amount%'
474 AND ac.transdate >= ? AND ac.transdate <= ?
475 group by invnumber,netamount having sum(ac.amount) <> ar.netamount|;
477 my $ar_amount_not_ac_amount = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
479 if ( scalar @{ $ar_amount_not_ac_amount } > 0 ) {
480 $self->tester->ok(0, "Folgende Ausgangsrechnungen haben einen falschen Netto-Wert im Nebenbuch:");
482 for my $ar_ac_amount_nok (@{ $ar_amount_not_ac_amount } ) {
483 $self->tester->diag("Rechnungsnummer: $ar_ac_amount_nok->{invnumber} Hauptbuch-Wert: $ar_ac_amount_nok->{amount}
484 Nebenbuch-Wert: $ar_ac_amount_nok->{netamount}");
487 $self->tester->ok(1, "Hauptbuch-Nettowert und Debitoren-Nebenbuch-Nettowert stimmen überein.");
492 sub check_ap_acc_trans_amount {
496 select sum(ac.amount) as amount, ap.invnumber,ap.netamount
497 from acc_trans ac left join ap on (ac.trans_id = ap.id)
498 WHERE (ac.chart_link like '%AP_amount%' OR ac.chart_link like '%IC_cogs%')
499 AND ac.transdate >= ? AND ac.transdate <= ?
500 group by invnumber,trans_id,netamount having sum(ac.amount) <> ap.netamount*-1|;
502 my $ap_amount_not_ac_amount = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
504 if ( scalar @{ $ap_amount_not_ac_amount } > 0 ) {
505 $self->tester->ok(0, "Folgende Eingangsrechnungen haben einen falschen Netto-Wert im Nebenbuch:");
507 for my $ap_ac_amount_nok (@{ $ap_amount_not_ac_amount } ) {
508 $self->tester->diag("Rechnungsnummer: $ap_ac_amount_nok->{invnumber} Hauptbuch-Wert: $ap_ac_amount_nok->{amount}
509 Nebenbuch-Wert: $ap_ac_amount_nok->{netamount}");
512 $self->tester->ok(1, "Hauptbuch-Nettowert und Kreditoren-Nebenbuch-Nettowert stimmen überein.");
518 sub check_missing_tax_bookings {
522 # check tax bookings. all taxkey <> 0 should have tax bookings in acc_trans
524 my $query = qq| select trans_id, chart.accno,transdate from acc_trans left join chart on (chart.id = acc_trans.chart_id)
525 WHERE taxkey NOT IN (SELECT taxkey from tax where rate=0) AND trans_id NOT IN
526 (select trans_id from acc_trans where chart_link ilike '%tax%' and trans_id IN
527 (SELECT trans_id from acc_trans where taxkey NOT IN (SELECT taxkey from tax where rate=0)))
528 AND transdate >= ? AND transdate <= ?|;
530 my $missing_tax_bookings = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
532 if ( scalar @{ $missing_tax_bookings } > 0 ) {
533 $self->tester->ok(0, "Folgende Konten weisen Buchungen ohne Steuerverknüpfung auf:");
535 for my $acc_trans_nok (@{ $missing_tax_bookings } ) {
536 $self->tester->diag("Kontonummer: $acc_trans_nok->{accno} Belegdatum: $acc_trans_nok->{transdate} Trans-ID: $acc_trans_nok->{trans_id}.
537 Kann über System -> Korrekturen im Hauptbuch bereinigt werden. Falls es ein Zahlungskonto ist, wurde
538 ggf. ein Brutto-Skonto-Konto mit einer Netto-Rechnung verknüpft. Kann nur per SQL geändert werden.");
541 $self->tester->ok(1, "Hauptbuch-Nettowert und Nebenbuch-Nettowert stimmen überein.");
545 sub check_bank_transactions_overpayments {
549 select id,amount,invoice_amount, purpose,transdate from bank_transactions where abs(invoice_amount) > abs(amount)
550 AND transdate >= ? AND transdate <= ? order by transdate|;
552 my $overpaids_bank_transactions = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
554 my $correct = 0 == @$overpaids_bank_transactions;
556 $self->tester->ok($correct, "Keine überbuchte Banktransaktion (der zugeordnete Betrag ist nicht höher, als der Überweisungsbetrag).");
557 for my $overpaid_bank_transaction (@{ $overpaids_bank_transactions }) {
558 $self->tester->diag("Überbuchte Bankbewegung!
559 Verwendungszweck: $overpaid_bank_transaction->{purpose}
560 Transaktionsdatum: $overpaid_bank_transaction->{transdate}
561 Betrag= $overpaid_bank_transaction->{amount} Zugeordneter Betrag = $overpaid_bank_transaction->{invoice_amount}
562 Bitte kontaktieren Sie Ihren kivitendo-DB-Admin, der die Überweisung wieder zurücksetzt (Table: bank_transactions Column: invoice_amount).");
566 sub check_ar_paid_acc_trans {
570 select sum(ac.amount) as paid_amount, ar.invnumber,ar.paid
571 from acc_trans ac left join ar on (ac.trans_id = ar.id)
572 WHERE ac.chart_link like '%AR_paid%'
573 AND ac.trans_id in (SELECT trans_id from acc_trans ac where ac.transdate >= ? AND ac.transdate <= ?)
574 group by invnumber, paid having sum(ac.amount) <> ar.paid*-1|;
576 my $ar_amount_not_ac_amount = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
578 if ( scalar @{ $ar_amount_not_ac_amount } > 0 ) {
579 $self->tester->ok(0, "Folgende Ausgangsrechnungen haben einen falschen Bezahl-Wert im Nebenbuch:");
581 for my $ar_ac_amount_nok (@{ $ar_amount_not_ac_amount } ) {
582 $self->tester->diag("Rechnungsnummer: $ar_ac_amount_nok->{invnumber} Hauptbuch-Wert: $ar_ac_amount_nok->{paid_amount}
583 Nebenbuch-Wert: $ar_ac_amount_nok->{paid}");
586 $self->tester->ok(1, "Hauptbuch-Bezahlwert und Debitoren-Nebenbuch-Bezahlwert stimmen überein.");
590 sub check_ap_paid_acc_trans {
594 select sum(ac.amount) as paid_amount, ap.invnumber,ap.paid
595 from acc_trans ac left join ap on (ac.trans_id = ap.id)
596 WHERE ac.chart_link like '%AP_paid%'
597 AND ac.trans_id in (SELECT trans_id from acc_trans ac where ac.transdate >= ? AND ac.transdate <= ?)
598 group by trans_id,invnumber,paid having sum(ac.amount) <> ap.paid|;
600 my $ap_amount_not_ac_amount = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
602 if ( scalar @{ $ap_amount_not_ac_amount } > 0 ) {
603 $self->tester->ok(0, "Folgende Eingangsrechnungen haben einen falschen Bezahl-Wert im Nebenbuch:");
605 for my $ap_ac_amount_nok (@{ $ap_amount_not_ac_amount } ) {
606 $self->tester->diag("Rechnungsnummer: $ap_ac_amount_nok->{invnumber} Hauptbuch-Wert: $ap_ac_amount_nok->{paid_amount}
607 Nebenbuch-Wert: $ap_ac_amount_nok->{paid}");
610 $self->tester->ok(1, "Hauptbuch Bezahl-Wert und Kreditoren-Nebenbuch-Bezahlwert stimmen überein.");
614 sub check_zero_amount_paid_but_datepaid_exists {
617 my $query = qq|(SELECT invnumber,datepaid from ar where datepaid is NOT NULL AND paid = 0
618 AND id not IN (select trans_id from acc_trans WHERE chart_link like '%paid%' AND acc_trans.trans_id = ar.id)
619 AND datepaid >= ? AND datepaid <= ?)
621 (SELECT invnumber,datepaid from ap where datepaid is NOT NULL AND paid = 0
622 AND id not IN (select trans_id from acc_trans WHERE chart_link like '%paid%' AND acc_trans.trans_id = ap.id)
623 AND datepaid >= ? AND datepaid <= ?)|;
625 my $datepaid_should_be_null = selectall_hashref_query($::form, $self->dbh, $query,
626 $self->fromdate, $self->todate,
627 $self->fromdate, $self->todate);
629 if ( scalar @{ $datepaid_should_be_null } > 0 ) {
630 $self->tester->ok(0, "Folgende Rechnungen haben ein Bezahl-Datum, aber keinen Bezahl-Wert im Nebenbuch:");
632 for my $datepaid_should_be_null_nok (@{ $datepaid_should_be_null } ) {
633 $self->tester->diag("Rechnungsnummer: $datepaid_should_be_null_nok->{invnumber}
634 Bezahl-Datum: $datepaid_should_be_null_nok->{datepaid}");
637 $self->tester->ok(1, "Kein Bezahl-Datum ohne Bezahl-Wert und ohne wirkliche Zahlungen gefunden (arap.datepaid, arap.paid konsistent).");
641 sub check_orphaned_reconciliated_links {
645 SELECT purpose from bank_transactions
646 WHERE cleared is true
647 AND NOT EXISTS (SELECT bank_transaction_id from reconciliation_links WHERE bank_transaction_id = bank_transactions.id)
648 AND transdate >= ? AND transdate <= ?|;
650 my $bt_cleared_no_link = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
652 if ( scalar @{ $bt_cleared_no_link } > 0 ) {
653 $self->tester->ok(0, "Verwaiste abgeglichene Bankbewegungen gefunden. Bei folgenden Bankbewegungen ist die abgleichende Verknüpfung gelöscht worden:");
655 for my $bt_orphaned (@{ $bt_cleared_no_link }) {
656 $self->tester->diag("Verwendungszweck: $bt_orphaned->{purpose}");
659 $self->tester->ok(1, "Keine verwaisten Einträge in abgeglichenen Bankbewegungen.");
663 sub check_recommended_client_settings {
668 # expand: check datev && check mark_as_paid
669 my %settings_values_nok = (
670 SL::DB::Default->get->is_changeable => 1,
671 SL::DB::Default->get->ar_changeable => 1,
672 SL::DB::Default->get->ap_changeable => 1,
673 SL::DB::Default->get->ir_changeable => 1,
674 SL::DB::Default->get->gl_changeable => 1,
677 foreach (keys %settings_values_nok) {
678 if ($_ == $settings_values_nok{$_}) {
679 $self->tester->ok(0, "Buchungskonfiguration: Mindestens ein Belegtyp ist immer änderbar.");
684 # payments more strict (avoid losing payments acc_trans_ids)
685 my $payments_ok = SL::DB::Default->get->payments_changeable == 0 ? 1 : 0;
686 $self->tester->ok(0, "Manuelle Zahlungen sind zu lange änderbar (Empfehlung: niemals).") unless $payments_ok;
688 $self->tester->ok(1, "Mandantenkonfiguration optimal eingestellt.") if ($payments_ok && $all_ok);
691 sub check_orphaned_bank_transaction_acc_trans_links {
695 SELECT purpose from bank_transactions
696 WHERE invoice_amount <> 0
697 AND NOT EXISTS (SELECT bank_transaction_id FROM bank_transaction_acc_trans WHERE bank_transaction_id = bank_transactions.id)
698 AND itime > (SELECT min(itime) from bank_transaction_acc_trans)
699 AND transdate >= ? AND transdate <= ?|;
701 my $bt_assigned_no_link = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
703 if ( scalar @{ $bt_assigned_no_link } > 0 ) {
704 $self->tester->ok(0, "Verwaiste Verknüpfungen zu Bankbewegungen gefunden. Bei folgenden Bankbewegungen ist eine interne Verknüpfung gelöscht worden:");
706 for my $bt_orphaned (@{ $bt_assigned_no_link }) {
707 $self->tester->diag("Verwendungszweck: $bt_orphaned->{purpose}");
710 $self->tester->ok(1, "Keine verwaisten Einträge in verknüpften Bankbewegungen (Richtung Bank).");
712 # check for deleted acc_trans_ids
714 SELECT purpose from bank_transactions
716 (SELECT bank_transaction_id from bank_transaction_acc_trans
717 WHERE NOT EXISTS (SELECT acc_trans.acc_trans_id FROM acc_trans WHERE acc_trans.acc_trans_id = bank_transaction_acc_trans.acc_trans_id)
718 AND transdate >= ? AND transdate <= ?)|;
720 my $bt_assigned_no_acc_trans = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
722 if ( scalar @{ $bt_assigned_no_acc_trans } > 0 ) {
723 $self->tester->ok(0, "Verwaiste Verknüpfungen zu Bankbewegungen gefunden. Bei folgenden Bankbewegungen ist eine interne Verknüpfung gelöscht worden:");
725 for my $bt_orphaned (@{ $bt_assigned_no_acc_trans }) {
726 $self->tester->diag("Verwendungszweck: $bt_orphaned->{purpose}");
729 $self->tester->ok(1, "Keine verwaisten Einträge in verknüpften Bankbewegungen (Richtung Buchung (Richtung Buchung)).");
733 sub check_consistent_itimes {
738 SELECT mtime, itime,gldate, acc_trans_id, trans_id
740 WHERE itime::date <> gldate::date
741 AND a.transdate >= ? and a.transdate <= ?|;
743 my $itimes_ac = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
745 if ( scalar @{ $itimes_ac } > 0 ) {
746 $self->tester->ok(0, "Inkonsistente Zeitstempel in der acc_trans gefunden. Bei folgenden ids:");
747 for my $bogus_time (@{ $itimes_ac }) {
748 $self->tester->diag("ID: $bogus_time->{trans_id} acc_trans_id: $bogus_time->{acc_trans_id} ");
751 $self->tester->ok(1, "Keine inkonsistenten Zeitstempel in der acc_trans.");
754 SELECT amount, itime, gldate, id
756 WHERE itime::date <> gldate::date
757 AND a.transdate >= ? and a.transdate <= ?|;
759 my $itimes_ap = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
761 if ( scalar @{ $itimes_ap } > 0 ) {
762 $self->tester->ok(0, "Inkonsistente Zeitstempel in ap gefunden. Bei folgenden ids:");
763 for my $bogus_time (@{ $itimes_ap }) {
764 $self->tester->diag("ID: $bogus_time->{id} itime: $bogus_time->{itime} mtime: $bogus_time->{mtime} ");
767 $self->tester->ok(1, "Keine inkonsistenten Zeitstempel in ap.");
770 SELECT amount, itime, gldate, id
772 WHERE itime::date <> gldate::date
773 AND a.transdate >= ? and a.transdate <= ?|;
775 my $itimes_ar = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
777 if ( scalar @{ $itimes_ap } > 0 ) {
778 $self->tester->ok(0, "Inkonsistente Zeitstempel in ar gefunden. Bei folgenden ids:");
779 for my $bogus_time (@{ $itimes_ar }) {
780 $self->tester->diag("ID: $bogus_time->{id} itime: $bogus_time->{itime} mtime: $bogus_time->{mtime} ");
783 $self->tester->ok(1, "Keine inkonsistenten Zeitstempel in ar.");
786 SELECT itime, gldate, id, mtime
788 WHERE itime::date <> gldate::date
789 AND a.transdate >= ? and a.transdate <= ?|;
791 my $itimes_gl = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
793 if ( scalar @{ $itimes_gl } > 0 ) {
794 $self->tester->ok(0, "Inkonsistente Zeitstempel in gl gefunden. Bei folgenden ids:");
795 for my $bogus_time (@{ $itimes_ar }) {
796 $self->tester->diag("ID: $bogus_time->{id} itime: $bogus_time->{itime} mtime: $bogus_time->{mtime} ");
799 $self->tester->ok(1, "Keine inkonsistenten Zeitstempel in gl.");
811 SL::BackgroundJob::SelfTest::Transactions - base tests
815 Several tests for data integrity.
819 G. Richardson E<lt>information@richardson-bueren.deE<gt>
820 Jan Büren E<lt>information@richardson-bueren.deE<gt>
821 Sven Schoeling E<lt>s.schoeling@linet-services.deE<gt>