1 ackage 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 => 20);
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;
45 # TODO FIXME calc dates better, unless this is wanted
46 $self->fromdate(DateTime->new(day => 1, month => 1, year => DateTime->today->year));
47 $self->todate($self->fromdate->clone->add(years => 1)->add(days => -1));
48 $self->dbh($::form->get_standard_dbh);
51 sub check_konten_mit_saldo_nicht_in_guv {
55 SELECT c.accno, c.description, c.category, SUM(a.amount) AS Saldo
58 WHERE c.id = a.chart_id
59 and (c.category like 'I' or c.category like 'E')
62 and a.transdate >= ? and a.transdate <= ?
63 GROUP BY c.accno,c.description,c.category,c.pos_bilanz,c.pos_eur
66 my $konten_nicht_in_guv = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
68 my $correct = 0 == scalar grep { $_->{Saldo} } @$konten_nicht_in_guv;
70 $self->tester->ok($correct, "Erfolgskonten mit Saldo nicht in GuV (Saldenvortragskonten können ignoriert werden, sollten aber 0 sein)");
72 for my $konto (@$konten_nicht_in_guv) {
73 $self->tester->diag($konto);
78 sub check_bilanzkonten_mit_pos_eur {
81 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)|;
83 my $bilanzkonten_mit_pos_eur = selectall_hashref_query($::form, $self->dbh, $query);
84 if (@$bilanzkonten_mit_pos_eur) {
85 $self->tester->ok(0, "Es gibt Bilanzkonten die der GuV/EÜR zugeordnet sind)");
86 $self->tester->diag("$_->{accno} $_->{description}") for @$bilanzkonten_mit_pos_eur;
88 $self->tester->ok(1, "Keine Bilanzkonten in der GuV");
92 sub check_balanced_individual_transactions {
96 select sum(ac.amount) as amount,trans_id,ar.invnumber as ar,ap.invnumber as ap,gl.reference as gl
98 left join ar on (ar.id = ac.trans_id)
99 left join ap on (ap.id = ac.trans_id)
100 left join gl on (gl.id = ac.trans_id)
101 where ac.transdate >= ? AND ac.transdate <= ?
102 group by trans_id,ar.invnumber,ap.invnumber,gl.reference
103 having sum(ac.amount) != 0;|;
105 my $acs = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
107 $self->tester->ok(0, "Es gibt unausgeglichene acc_trans-Transaktionen:");
108 for my $ac (@{ $acs }) {
109 $self->tester->diag("trans_id: $ac->{trans_id}, amount = $ac->{amount}, ar: $ac->{ar} ap: $ac->{ap} gl: $ac->{gl}");
112 $self->tester->ok(1, "Alle acc_trans Transaktionen ergeben in Summe 0, keine unausgeglichenen Transaktionen");
116 sub check_verwaiste_acc_trans_eintraege {
120 select trans_id,amount,accno,description from acc_trans a
121 left join chart c on (c.id = a.chart_id)
122 where trans_id not in (select id from gl union select id from ar union select id from ap order by id)
123 and a.transdate >= ? and a.transdate <= ? ;|;
125 my $verwaiste_acs = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
126 if (@$verwaiste_acs) {
127 $self->tester->ok(0, "Es gibt verwaiste acc-trans Einträge! (wo ar/ap/gl-Eintrag fehlt)");
128 $self->tester->diag($_) for @$verwaiste_acs;
130 $self->tester->ok(1, "Keine verwaisten acc-trans Einträge (wo ar/ap/gl-Eintrag fehlt)");
134 sub check_verwaiste_invoice_eintraege {
135 # this check is always run for all invoice entries in the entire database
138 select * from invoice i
139 where trans_id not in (select id from ar union select id from ap order by id) |;
141 my $verwaiste_invoice = selectall_hashref_query($::form, $self->dbh, $query);
142 if (@$verwaiste_invoice) {
143 $self->tester->ok(0, "Es gibt verwaiste invoice Einträge! (wo ar/ap-Eintrag fehlt)");
144 for my $invoice ( @{ $verwaiste_invoice }) {
145 $self->tester->diag("invoice: id: $invoice->{id} trans_id: $invoice->{trans_id} description: $invoice->{description} itime: $invoice->{itime}");
148 $self->tester->ok(1, "Keine verwaisten invoice Einträge (wo ar/ap-Eintrag fehlt)"); }
151 sub check_netamount_laut_invoice_ar {
154 select sum(round(cast(i.qty*(i.fxsellprice * (1-i.discount)) as numeric), 2))
156 left join ar a on (a.id = i.trans_id)
157 where a.transdate >= ? and a.transdate <= ?;|;
158 my ($netamount_laut_invoice) = selectfirst_array_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
160 $query = qq| select sum(netamount) from ar where transdate >= ? and transdate <= ? AND invoice; |;
161 my ($netamount_laut_ar) = selectfirst_array_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
163 # should be enough to get a diff below 1. We have currently the following issues:
164 # verkaufsbericht berücksichtigt keinen rabatt
165 # fxsellprice ist mit mwst-inklusive
166 my $correct = abs($netamount_laut_invoice - $netamount_laut_ar) < 1;
168 $self->tester->ok($correct, "Summe laut Verkaufsbericht sollte gleich Summe aus Verkauf -> Berichte -> Rechnungen sein");
170 $self->tester->diag("Netto-Summe laut Verkaufsbericht (invoice): $netamount_laut_invoice");
171 $self->tester->diag("Netto-Summe laut Verkauf -> Berichte -> Rechnungen: $netamount_laut_ar");
175 sub check_invnumbers_unique {
178 my $query = qq| select invnumber,count(invnumber) as count from ar
179 where transdate >= ? and transdate <= ?
181 having count(invnumber) > 1; |;
182 my $non_unique_invnumbers = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
184 if (@$non_unique_invnumbers) {
185 $self->tester->ok(0, "Es gibt doppelte Rechnungsnummern");
186 for my $invnumber (@{ $non_unique_invnumbers }) {
187 $self->tester->diag("invnumber: $invnumber->{invnumber} $invnumber->{count}x");
190 $self->tester->ok(1, "Alle Rechnungsnummern sind eindeutig");
194 sub check_summe_stornobuchungen {
198 select sum(amount) from ar a JOIN customer c ON (a.customer_id = c.id)
200 AND a.transdate >= ? and a.transdate <= ?|;
201 my ($summe_stornobuchungen_ar) = selectfirst_array_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
204 select sum(amount) from ap a JOIN vendor c ON (a.vendor_id = c.id)
206 AND a.transdate >= ? and a.transdate <= ?|;
207 my ($summe_stornobuchungen_ap) = selectfirst_array_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
209 $self->tester->ok($summe_stornobuchungen_ap == 0, 'Summe aller Einkaufsrechnungen (stornos + stornierte) soll 0 sein');
210 $self->tester->ok($summe_stornobuchungen_ar == 0, 'Summe aller Verkaufsrechnungen (stornos + stornierte) soll 0 sein');
211 $self->tester->diag("Summe Verkaufsrechnungen (ar): $summe_stornobuchungen_ar") if $summe_stornobuchungen_ar;
212 $self->tester->diag("Summe Einkaufsrechnungen (ap): $summe_stornobuchungen_ap") if $summe_stornobuchungen_ap;
219 select invnumber,paid,
220 (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 ,
221 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
224 (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
226 AND transdate >= ? and transdate <= ?
229 my $paid_diffs_ar = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
231 my $errors = scalar grep { $_->{diff} != 0 } @$paid_diffs_ar;
233 $self->tester->ok(!$errors, "Vergleich ar paid mit acc_trans AR_paid");
235 for my $paid_diff_ar (@{ $paid_diffs_ar }) {
236 next if $paid_diff_ar->{diff} == 0;
237 $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}");
245 select invnumber,paid,
246 (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 ,
247 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
250 (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
251 AND transdate >= ? and transdate <= ?
254 my $paid_diffs_ap = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
256 my $errors = scalar grep { $_->{diff} != 0 } @$paid_diffs_ap;
258 $self->tester->ok(!$errors, "Vergleich ap paid mit acc_trans AP_paid");
259 for my $paid_diff_ap (@{ $paid_diffs_ap }) {
260 next if $paid_diff_ap->{diff} == 0;
261 $self->tester->diag("ap invnumber: $paid_diff_ap->{invnumber} : paid: $paid_diff_ap->{paid} acc_paid= $paid_diff_ap->{accpaid} diff: $paid_diff_ap->{diff}");
265 sub check_ar_overpayments {
269 select invnumber,paid,amount,transdate,c.customernumber,c.name from ar left join customer c on (ar.customer_id = c.id)
270 where abs(paid) > abs(amount)
271 AND transdate >= ? and transdate <= ?
272 order by invnumber;|;
274 my $overpaids_ar = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
276 my $correct = 0 == @$overpaids_ar;
278 $self->tester->ok($correct, "Keine Überzahlungen laut ar.paid");
279 for my $overpaid_ar (@{ $overpaids_ar }) {
280 $self->tester->diag("ar invnumber: $overpaid_ar->{invnumber} : paid: $overpaid_ar->{paid} amount= $overpaid_ar->{amount} transdate = $overpaid_ar->{transdate}");
284 sub check_ap_overpayments {
288 select invnumber,paid,amount,transdate,vc.vendornumber,vc.name from ap left join vendor vc on (ap.vendor_id = vc.id)
289 where abs(paid) > abs(amount)
290 AND transdate >= ? and transdate <= ?
291 order by invnumber;|;
293 my $overpaids_ap = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
295 my $correct = 0 == @$overpaids_ap;
297 $self->tester->ok($correct, "Überzahlungen laut ap.paid:");
298 for my $overpaid_ap (@{ $overpaids_ap }) {
299 $self->tester->diag("ap invnumber: $overpaid_ap->{invnumber} : paid: $overpaid_ap->{paid} amount= $overpaid_ap->{amount} transdate = $overpaid_ap->{transdate}");
303 sub check_paid_stornos {
307 SELECT ar.invnumber,sum(amount - COALESCE((SELECT sum(amount)*-1
308 FROM acc_trans LEFT JOIN chart ON (acc_trans.chart_id=chart.id)
309 WHERE link ilike '%paid%' AND acc_trans.trans_id=ar.id ),0)) as "open"
313 AND (ar.customer_id = customer.id)
314 AND ar.transdate >= ? and ar.transdate <= ?
315 GROUP BY ar.invnumber|;
316 my $paid_stornos = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
318 $self->tester->ok(0 == @$paid_stornos, "Keine bezahlten Stornos");
319 for my $paid_storno (@{ $paid_stornos }) {
320 $self->tester->diag("invnumber: $paid_storno->{invnumber} offen: $paid_storno->{open}");
324 sub check_stornos_ohne_partner {
328 SELECT (SELECT cast ('ar' as text)) as invoice ,ar.id,invnumber,storno,amount,transdate,type,customernumber as cv_number
330 LEFT JOIN customer c on (c.id = ar.customer_id)
331 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)
332 AND ar.transdate >= ? and ar.transdate <= ?
334 SELECT (SELECT cast ('ap' as text)) as invoice,ap.id,invnumber,storno,amount,transdate,type,vendornumber as cv_number
336 LEFT JOIN vendor v on (v.id = ap.vendor_id)
337 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)
338 AND ap.transdate >= ? and ap.transdate <= ?|;
340 my $stornos_ohne_partner = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate,
341 $self->fromdate, $self->todate);
343 $self->tester->ok(@$stornos_ohne_partner == 0, 'Es sollte keine Stornos ohne Partner geben');
344 if (@$stornos_ohne_partner) {
345 $self->tester->diag("Stornos ohne Partner, oder Storno über Jahreswechsel hinaus");
347 my $stornoheader = 0;
348 for my $storno (@{ $stornos_ohne_partner }) {
349 if (!$stornoheader++) {
350 $self->tester->diag(join "\t", keys %$storno);
352 $self->tester->diag(join "\t", map { $storno->{$_} } keys %$storno);
356 sub check_overpayments {
359 # Vergleich ar.paid und das was laut acc_trans bezahlt wurde
360 # "als bezahlt markieren" ohne sauberes Ausbuchen führt zu Differenzen bei offenen Forderungen
361 # geht nur auf wenn acc_trans Zahlungseingänge auch im Untersuchungszeitraum lagen
362 # Stornos werden rausgefiltert
365 invnumber,customernumber,name,ar.transdate,ar.datepaid,
367 amount-paid as "open via ar",
368 paid as "paid via ar",
369 coalesce((SELECT sum(amount)*-1 FROM acc_trans LEFT JOIN chart ON (acc_trans.chart_id=chart.id)
370 WHERE link ilike '%paid%' AND acc_trans.trans_id=ar.id AND acc_trans.transdate <= ?),0) as "paid via acc_trans"
371 FROM ar left join customer c on (c.id = ar.customer_id)
374 AND transdate >= ? AND transdate <= ?|;
376 my $invoices = selectall_hashref_query($::form, $self->dbh, $query, $self->todate, $self->fromdate, $self->todate);
378 my $count_overpayments = scalar grep {
379 $_->{"paid via ar"} != $_->{"paid via acc_trans"}
380 || ( $_->{"amount"} - $_->{"paid via acc_trans"} != $_->{"open via ar"}
381 && $_->{"paid via ar"} != $_->{"paid via acc_trans"} )
384 $self->tester->ok($count_overpayments == 0, 'Vergleich ar.paid und das was laut acc_trans bezahlt wurde');
386 if ($count_overpayments) {
387 for my $invoice (@{ $invoices }) {
388 if ($invoice->{"paid via ar"} != $invoice->{"paid via acc_trans"}) {
389 $self->tester->diag("paid via ar (@{[ $invoice->{'paid via ar'} * 1 ]}) != paid via acc_trans (@{[ $invoice->{'paid via acc_trans'} * 1 ]}) (at least until transdate!)");
390 if (defined $invoice->{datepaid}) {
391 $self->tester->diag("datepaid = $invoice->{datepaid})");
393 $self->tester->diag("Überzahlung bei Rechnung: $invoice->{invnumber}") if $invoice->{"paid via acc_trans"} > $invoice->{amount};
394 } elsif ( $invoice->{"amount"} - $invoice->{"paid via acc_trans"} != $invoice->{"open via ar"} && $invoice->{"paid via ar"} != $invoice->{"paid via acc_trans"}) {
395 $self->tester->diag("amount - paid_via_acc_trans != open_via_ar");
396 $self->tester->diag("Überzahlung bei Rechnung: $invoice->{invnumber}") if $invoice->{"paid via acc_trans"} > $invoice->{amount};
404 sub calc_saldenvortraege {
407 my $saldenvortragskonto = '9000';
409 # Saldo Saldenvortragskonto 9000 am Jahresanfang
411 select sum(amount) from acc_trans where chart_id = (select id from chart where accno = ?) and transdate <= ?|;
412 my ($saldo_9000_jahresanfang) = selectfirst_array_query($::form, $self->dbh, $query, $saldenvortragskonto, DateTime->new(day => 1, month => 1, year => DateTime->today->year));
413 $self->tester->diag("Saldo 9000 am 01.01.@{[DateTime->today->year]}: @{[ $saldo_9000_jahresanfang * 1 ]} (sollte 0 sein)");
415 # Saldo Saldenvortragskonto 9000 am Jahresende
417 select sum(amount) from acc_trans where chart_id = (select id from chart where accno = ?) and transdate <= ?|;
418 my ($saldo_9000_jahresende) = selectfirst_array_query($::form, $self->dbh, $query, $saldenvortragskonto, DateTime->new(day => 31, month => 12, year => DateTime->today->year));
419 $self->tester->diag("Saldo $saldenvortragskonto am 31.12.@{[DateTime->today->year]}: @{[ $saldo_9000_jahresende * 1 ]} (sollte 0 sein)");
422 sub check_every_account_with_taxkey {
425 my $query = qq|SELECT accno, description FROM chart WHERE id NOT IN (select chart_id from taxkeys)|;
426 my $accounts_without_tk = selectall_hashref_query($::form, $self->dbh, $query);
428 if ( scalar @{ $accounts_without_tk } > 0 ){
429 $self->tester->ok(0, "Folgende Konten haben keinen gültigen Steuerschlüssel:");
431 for my $account_without_tk (@{ $accounts_without_tk } ) {
432 $self->tester->diag("Kontonummer: $account_without_tk->{accno} Beschreibung: $account_without_tk->{description}");
435 $self->tester->ok(1, "Jedes Konto hat einen gültigen Steuerschlüssel!");
439 sub check_ar_acc_trans_amount {
443 select sum(ac.amount) as amount, ar.invnumber,ar.netamount
444 from acc_trans ac left join ar on (ac.trans_id = ar.id)
445 WHERE ac.chart_link like 'AR_amount%'
446 AND ac.transdate >= ? AND ac.transdate <= ?
447 group by invnumber,netamount having sum(ac.amount) <> ar.netamount|;
449 my $ar_amount_not_ac_amount = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
451 if ( scalar @{ $ar_amount_not_ac_amount } > 0 ) {
452 $self->tester->ok(0, "Folgende Ausgangsrechnungen haben einen falschen Netto-Wert im Nebenbuch:");
454 for my $ar_ac_amount_nok (@{ $ar_amount_not_ac_amount } ) {
455 $self->tester->diag("Rechnungsnummer: $ar_ac_amount_nok->{invnumber} Hauptbuch-Wert: $ar_ac_amount_nok->{amount}
456 Nebenbuch-Wert: $ar_ac_amount_nok->{netamount}");
459 $self->tester->ok(1, "Hauptbuch-Nettowert und Debitoren-Nebenbuch-Nettowert stimmen überein.");
464 sub check_ap_acc_trans_amount {
468 select sum(ac.amount) as amount, ap.invnumber,ap.netamount
469 from acc_trans ac left join ap on (ac.trans_id = ap.id)
470 WHERE ac.chart_link like 'AR_amount%'
471 AND ac.transdate >= ? AND ac.transdate <= ?
472 group by invnumber,netamount having sum(ac.amount) <> ap.netamount*-1|;
474 my $ap_amount_not_ac_amount = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
476 if ( scalar @{ $ap_amount_not_ac_amount } > 0 ) {
477 $self->tester->ok(0, "Folgende Eingangsrechnungen haben einen falschen Netto-Wert im Nebenbuch:");
479 for my $ap_ac_amount_nok (@{ $ap_amount_not_ac_amount } ) {
480 $self->tester->diag("Rechnungsnummer: $ap_ac_amount_nok->{invnumber} Hauptbuch-Wert: $ap_ac_amount_nok->{amount}
481 Nebenbuch-Wert: $ap_ac_amount_nok->{netamount}");
484 $self->tester->ok(1, "Hauptbuch-Nettowert und Kreditoren-Nebenbuch-Nettowert stimmen überein.");
490 sub check_missing_tax_bookings {
494 # check tax bookings. all taxkey <> 0 should have tax bookings in acc_trans
496 my $query = qq| select trans_id, chart.accno,transdate from acc_trans left join chart on (chart.id = acc_trans.chart_id)
497 WHERE taxkey <> 0 AND trans_id NOT IN
498 (select trans_id from acc_trans where chart_link ilike '%tax%' and trans_id IN
499 (SELECT trans_id from acc_trans where taxkey <> 0))
500 AND transdate >= ? AND transdate <= ?|;
502 my $missing_tax_bookings = selectall_hashref_query($::form, $self->dbh, $query, $self->fromdate, $self->todate);
504 if ( scalar @{ $missing_tax_bookings } > 0 ) {
505 $self->tester->ok(0, "Folgende Konten weisen Buchungen ohne Steuer auf:");
507 for my $acc_trans_nok (@{ $missing_tax_bookings } ) {
508 $self->tester->diag("Kontonummer: $acc_trans_nok->{accno} Belegdatum: $acc_trans_nok->{transdate} Trans-ID: $acc_trans_nok->{trans_id}.
509 Kann über System -> Korrekturen im Hauptbuch bereinigt werden.");
512 $self->tester->ok(1, "Hauptbuch-Nettowert und Nebenbuch-Nettowert stimmen überein.");
525 SL::BackgroundJob::SelfTest::Transactions - base tests
529 Several tests for data integrity.
537 G. Richardson E<lt>information@richardson-bueren.deE<gt>
538 Jan Büren E<lt>information@richardson-bueren.deE<gt>
539 Sven Schoeling E<lt>s.schoeling@linet-services.deE<gt>