From ef17e41a8364c6c97566a054768f573659dbec79 Mon Sep 17 00:00:00 2001 From: Moritz Bunkus Date: Wed, 11 Apr 2007 14:06:26 +0000 Subject: [PATCH] =?utf8?q?Umstellung=20der=20Form.pm=20auf=20die=20Verwend?= =?utf8?q?ung=20parametrisierter=20Queries=20zur=20Vermeidung=20von=20SQL?= =?utf8?q?=20injection.=20Zus=C3=A4tzlich=20etwas=20Kosmetik=20(trailing?= =?utf8?q?=20whitespace,=20TABs=20entfernt).?= MIME-Version: 1.0 Content-Type: text/plain; charset=utf8 Content-Transfer-Encoding: 8bit --- SL/Form.pm | 1191 ++++++++++++++++--------------------------- SL/GL.pm | 8 - SL/IC.pm | 2 +- SL/IR.pm | 5 +- SL/IS.pm | 10 +- SL/LICENSES.pm | 4 +- bin/mozilla/arap.pl | 2 + 7 files changed, 441 insertions(+), 781 deletions(-) diff --git a/SL/Form.pm b/SL/Form.pm index 5e0b9fd53..6b380bd6f 100644 --- a/SL/Form.pm +++ b/SL/Form.pm @@ -170,12 +170,7 @@ sub debug { sub escape { $main::lxdebug->enter_sub(2); - my ($self, $str, $beenthere) = @_; - - # for Apache 2 we escape strings twice - #if (($ENV{SERVER_SOFTWARE} =~ /Apache\/2/) && !$beenthere) { - # $str = $self->escape($str, 1); - #} + my ($self, $str) = @_; $str =~ s/([^a-zA-Z0-9_.-])/sprintf("%%%02x", ord($1))/ge; @@ -244,17 +239,11 @@ sub hide_form { my $self = shift; if (@_) { - for (@_) { - print qq|\n|; - } + map({ print($main::cgi->hidden("-name" => $_, "-default" => $self->{$_}) . "\n"); } @_); } else { - delete $self->{header}; for (sort keys %$self) { - print qq|\n|; + next if (($_ eq "header") || (ref($self->{$_}) ne "")); + print($main::cgi->hidden("-name" => $_, "-default" => $self->{$_}) . "\n"); } } @@ -430,15 +419,15 @@ function fokus(){document.$self->{fokus}.focus();} - + $extra_code @@ -597,7 +586,7 @@ sub write_trigger { { inputField : "| . (shift) . qq|", ifFormat :"$ifFormat", - align : "| . (shift) . qq|", + align : "| . (shift) . qq|", button : "| . (shift) . qq|" } ); @@ -648,7 +637,7 @@ sub format_amount { $main::lxdebug->enter_sub(2); my ($self, $myconfig, $amount, $places, $dash) = @_; - + if ($amount eq "") { $amount = 0; } @@ -680,7 +669,7 @@ sub format_amount { ($dash =~ /DRCR/) ? ($neg ? "$amount DR" : "$amount CR" ) : ($neg ? "-$amount" : "$amount" ) ; }; - + $main::lxdebug->leave_sub(2); return $amount; @@ -750,7 +739,7 @@ sub parse_template { (!$self->{"format"} && ($self->{"IN"} =~ /xml$/i))) { $template = XMLTemplate->new($self->{"IN"}, $self, $myconfig, $userspath); } elsif ( $self->{"format"} =~ /elsterwinston/i ) { - $template = XMLTemplate->new($self->{"IN"}, $self, $myconfig, $userspath); + $template = XMLTemplate->new($self->{"IN"}, $self, $myconfig, $userspath); } elsif ( $self->{"format"} =~ /elstertaxbird/i ) { $template = XMLTemplate->new($self->{"IN"}, $self, $myconfig, $userspath); } elsif ( defined $self->{'format'}) { @@ -758,7 +747,7 @@ sub parse_template { } elsif ( $self->{'format'} eq '' ) { $self->error("No Outputformat given: $self->{'format'}"); } else { #Catch the rest - $self->error("Outputformat not defined: $self->{'format'}"); + $self->error("Outputformat not defined: $self->{'format'}"); } # Copy the notes from the invoice/sales order etc. back to the variable "notes" because that is where most templates expect it to be. @@ -1004,16 +993,14 @@ sub dbconnect_noauto { sub update_balance { $main::lxdebug->enter_sub(); - my ($self, $dbh, $table, $field, $where, $value) = @_; + my ($self, $dbh, $table, $field, $where, $value, @values) = @_; # if we have a value, go do it if ($value != 0) { # retrieve balance from table my $query = "SELECT $field FROM $table WHERE $where FOR UPDATE"; - my $sth = $dbh->prepare($query); - - $sth->execute || $self->dberror($query); + my $sth = prepare_execute_query($self, $dbh, $query, @values); my ($balance) = $sth->fetchrow_array; $sth->finish; @@ -1021,7 +1008,7 @@ sub update_balance { # update balance $query = "UPDATE $table SET $field = $balance WHERE $where"; - $dbh->do($query) || $self->dberror($query); + do_query($self, $dbh, $query, @values); } $main::lxdebug->leave_sub(); } @@ -1038,11 +1025,9 @@ sub update_exchangerate { } my $query = qq|SELECT e.curr FROM exchangerate e - WHERE e.curr = '$curr' - AND e.transdate = '$transdate' - FOR UPDATE|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); + WHERE e.curr = ? AND e.transdate = ? + FOR UPDATE|; + my $sth = prepare_execute_query($self, $dbh, $query, $curr, $transdate); my $set; if ($buy != 0 && $sell != 0) { @@ -1056,14 +1041,14 @@ sub update_exchangerate { if ($sth->fetchrow_array) { $query = qq|UPDATE exchangerate SET $set - WHERE curr = '$curr' - AND transdate = '$transdate'|; + WHERE curr = ? + AND transdate = ?|; } else { $query = qq|INSERT INTO exchangerate (curr, buy, sell, transdate) - VALUES ('$curr', $buy, $sell, '$transdate')|; + VALUES (?, $buy, $sell, ?)|; } $sth->finish; - $dbh->do($query) || $self->dberror($query); + do_query($self, $dbh, $query, $curr, $transdate); $main::lxdebug->leave_sub(); } @@ -1097,13 +1082,8 @@ sub get_exchangerate { } my $query = qq|SELECT e.$fld FROM exchangerate e - WHERE e.curr = '$curr' - AND e.transdate = '$transdate'|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - my ($exchangerate) = $sth->fetchrow_array; - $sth->finish; + WHERE e.curr = ? AND e.transdate = ?|; + my ($exchangerate) = selectrow_query($self, $dbh, $query, $curr, $transdate); if (!$exchangerate) { $exchangerate = 1; @@ -1114,6 +1094,28 @@ sub get_exchangerate { return $exchangerate; } +sub check_exchangerate { + $main::lxdebug->enter_sub(); + + my ($self, $myconfig, $currency, $transdate, $fld) = @_; + + unless ($transdate) { + $main::lxdebug->leave_sub(); + return ""; + } + + my $dbh = $self->dbconnect($myconfig); + + my $query = qq|SELECT e.$fld FROM exchangerate e + WHERE e.curr = ? AND e.transdate = ?|; + my ($exchangerate) = selectrow_query($self, $dbh, $query, $currency, $transdate); + $dbh->disconnect; + + $main::lxdebug->leave_sub(); + + return $exchangerate; +} + sub set_payment_options { $main::lxdebug->enter_sub(); @@ -1124,8 +1126,7 @@ sub set_payment_options { my $dbh = $self->dbconnect($myconfig); my $query = - qq|SELECT p.terms_netto, p.terms_skonto, p.percent_skonto, | . - qq|p.description_long | . + qq|SELECT p.terms_netto, p.terms_skonto, p.percent_skonto, p.description_long | . qq|FROM payment_terms p | . qq|WHERE p.id = ?|; @@ -1142,11 +1143,10 @@ sub set_payment_options { } $query = - qq|SELECT date '$transdate' + $self->{terms_netto} AS netto_date, | . - qq|date '$transdate' + $self->{terms_skonto} AS skonto_date | . - qq|FROM payment_terms LIMIT 1|; + qq|SELECT ?::date + ?::integer AS netto_date, ?::date + ?::integer AS skonto_date | . + qq|FROM payment_terms|; ($self->{netto_date}, $self->{skonto_date}) = - selectrow_query($self, $dbh, $query); + selectrow_query($self, $dbh, $query, $transdate, $self->{terms_netto}, $transdate, $self->{terms_skonto}); my $total = ($self->{invtotal}) ? $self->{invtotal} : $self->{ordtotal}; my $skonto_amount = $self->parse_amount($myconfig, $total) * @@ -1157,8 +1157,7 @@ sub set_payment_options { if ($self->{"language_id"}) { $query = - qq|SELECT t.description_long, | . - qq|l.output_numberformat, l.output_dateformat, l.output_longdates | . + qq|SELECT t.description_long, l.output_numberformat, l.output_dateformat, l.output_longdates | . qq|FROM translation_payment_terms t | . qq|LEFT JOIN language l ON t.language_id = l.id | . qq|WHERE (t.language_id = ?) AND (t.payment_terms_id = ?)|; @@ -1206,33 +1205,6 @@ sub set_payment_options { } -sub check_exchangerate { - $main::lxdebug->enter_sub(); - - my ($self, $myconfig, $currency, $transdate, $fld) = @_; - - unless ($transdate) { - $main::lxdebug->leave_sub(); - return ""; - } - - my $dbh = $self->dbconnect($myconfig); - - my $query = qq|SELECT e.$fld FROM exchangerate e - WHERE e.curr = '$currency' - AND e.transdate = '$transdate'|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - my ($exchangerate) = $sth->fetchrow_array; - $sth->finish; - $dbh->disconnect; - - $main::lxdebug->leave_sub(); - - return $exchangerate; -} - sub get_template_language { $main::lxdebug->enter_sub(); @@ -1241,17 +1213,9 @@ sub get_template_language { my $template_code = ""; if ($self->{language_id}) { - my $dbh = $self->dbconnect($myconfig); - - - my $query = qq|SELECT l.template_code FROM language l - WHERE l.id = $self->{language_id}|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - ($template_code) = $sth->fetchrow_array; - $sth->finish; + my $query = qq|SELECT template_code FROM language WHERE id = ?|; + ($template_code) = selectrow_query($self, $dbh, $query, $self->{language_id}); $dbh->disconnect; } @@ -1268,17 +1232,9 @@ sub get_printer_code { my $template_code = ""; if ($self->{printer_id}) { - my $dbh = $self->dbconnect($myconfig); - - - my $query = qq|SELECT p.template_code,p.printer_command FROM printers p - WHERE p.id = $self->{printer_id}|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - ($template_code, $self->{printer_command}) = $sth->fetchrow_array; - $sth->finish; + my $query = qq|SELECT template_code, printer_command FROM printers WHERE id = ?|; + ($template_code, $self->{printer_command}) = selectrow_query($self, $dbh, $query, $self->{printer_id}); $dbh->disconnect; } @@ -1295,88 +1251,71 @@ sub get_shipto { my $template_code = ""; if ($self->{shipto_id}) { - my $dbh = $self->dbconnect($myconfig); - - - my $query = qq|SELECT s.* FROM shipto s - WHERE s.shipto_id = $self->{shipto_id}|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - $ref = $sth->fetchrow_hashref(NAME_lc); - map { $self->{$_} = $ref->{$_} } keys %$ref; - $sth->finish; + my $query = qq|SELECT * FROM shipto WHERE shipto_id = ?|; + my $ref = selectfirst_hashref_query($self, $dbh, $query, $self->{shipto_id}); + map({ $self->{$_} = $ref->{$_} } keys(%$ref)); $dbh->disconnect; } $main::lxdebug->leave_sub(); - } sub add_shipto { $main::lxdebug->enter_sub(); my ($self, $dbh, $id, $module) = @_; -##LINET + my $shipto; - foreach my $item ( - qw(name department_1 department_2 street zipcode city country contact phone fax email) - ) { + my @values; + foreach my $item (qw(name department_1 department_2 street zipcode city country + contact phone fax email)) { if ($self->{"shipto$item"}) { $shipto = 1 if ($self->{$item} ne $self->{"shipto$item"}); } - $self->{"shipto$item"} =~ s/\'/\'\'/g; + push(@values, $self->{"shipto${item}"}); } if ($shipto) { if ($self->{shipto_id}) { - my $query = qq| UPDATE shipto set - shiptoname = '$self->{shiptoname}', - shiptodepartment_1 = '$self->{shiptodepartment_1}', - shiptodepartment_2 = '$self->{shiptodepartment_2}', - shiptostreet = '$self->{shiptostreet}', - shiptozipcode = '$self->{shiptozipcode}', - shiptocity = '$self->{shiptocity}', - shiptocountry = '$self->{shiptocountry}', - shiptocontact = '$self->{shiptocontact}', - shiptophone = '$self->{shiptophone}', - shiptofax = '$self->{shiptofax}', - shiptoemail = '$self->{shiptoemail}' - WHERE shipto_id = $self->{shipto_id}|; - $dbh->do($query) || $self->dberror($query); + my $query = qq|UPDATE shipto set + shiptoname = ?, + shiptodepartment_1 = ?, + shiptodepartment_2 = ?, + shiptostreet = ?, + shiptozipcode = ?, + shiptocity = ?, + shiptocountry = ?, + shiptocontact = ?, + shiptophone = ?, + shiptofax = ?, + shiptoemail = ? + WHERE shipto_id = ?|; + do_query($self, $dbh, $query, @values, $self->{shipto_id}); } else { my $query = qq|SELECT * FROM shipto - WHERE shiptoname = '$self->{shiptoname}' AND - shiptodepartment_1 = '$self->{shiptodepartment_1}' AND - shiptodepartment_2 = '$self->{shiptodepartment_2}' AND - shiptostreet = '$self->{shiptostreet}' AND - shiptozipcode = '$self->{shiptozipcode}' AND - shiptocity = '$self->{shiptocity}' AND - shiptocountry = '$self->{shiptocountry}' AND - shiptocontact = '$self->{shiptocontact}' AND - shiptophone = '$self->{shiptophone}' AND - shiptofax = '$self->{shiptofax}' AND - shiptoemail = '$self->{shiptoemail}' - | ; - my $sth = $dbh->prepare($query); - $sth->execute() || $self->dberror($query); - my $insert_check = $sth->fetch(); - $sth->finish(); + WHERE shiptoname = ? AND + shiptodepartment_1 = ? AND + shiptodepartment_2 = ? AND + shiptostreet = ? AND + shiptozipcode = ? AND + shiptocity = ? AND + shiptocountry = ? AND + shiptocontact = ? AND + shiptophone = ? AND + shiptofax = ? AND + shiptoemail = ?|; + my $insert_check = selectfirst_hashref_query($self, $dbh, $query, @values); if(!$insert_check){ $query = - qq|INSERT INTO shipto (trans_id, shiptoname, shiptodepartment_1, - shiptodepartment_2, shiptostreet, - shiptozipcode, shiptocity, shiptocountry, shiptocontact, - shiptophone, shiptofax, shiptoemail, module) VALUES ($id, - '$self->{shiptoname}', '$self->{shiptodepartment_1}', '$self->{shiptodepartment_2}', '$self->{shiptostreet}', - '$self->{shiptozipcode}', '$self->{shiptocity}', - '$self->{shiptocountry}', '$self->{shiptocontact}', - '$self->{shiptophone}', '$self->{shiptofax}', - '$self->{shiptoemail}', '$module')|; - $dbh->do($query) || $self->dberror($query); + qq|INSERT INTO shipto (trans_id, shiptoname, shiptodepartment_1, shiptodepartment_2, + shiptostreet, shiptozipcode, shiptocity, shiptocountry, + shiptocontact, shiptophone, shiptofax, shiptoemail, module) + VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)|; + do_query($self, $dbh, $query, $id, @values, $module); } } } -##/LINET + $main::lxdebug->leave_sub(); } @@ -1385,16 +1324,10 @@ sub get_employee { my ($self, $dbh) = @_; - my $query = qq|SELECT e.id, e.name FROM employee e - WHERE e.login = '$self->{login}'|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - ($self->{employee_id}, $self->{employee}) = $sth->fetchrow_array; + my $query = qq|SELECT id, name FROM employee WHERE login = ?|; + ($self->{employee_id}, $self->{employee}) = selectrow_query($self, $dbh, $query, $self->{login}); $self->{employee_id} *= 1; - $sth->finish; - $main::lxdebug->leave_sub(); } @@ -1435,45 +1368,28 @@ sub get_duedate { my ($self, $myconfig) = @_; my $dbh = $self->dbconnect($myconfig); - my $query = qq|SELECT current_date+terms_netto FROM payment_terms - WHERE id = '$self->{payment_id}'|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - ($self->{duedate}) = $sth->fetchrow_array; - - $sth->finish; + my $query = qq|SELECT current_date + terms_netto FROM payment_terms WHERE id = ?|; + ($self->{duedate}) = selectrow_query($self, $dbh, $query, $self->{payment_id}); + $dbh->disconnect(); $main::lxdebug->leave_sub(); } -# get contacts for id, if no contact return {"","","","",""} sub _get_contacts { $main::lxdebug->enter_sub(); my ($self, $dbh, $id, $key) = @_; $key = "all_contacts" unless ($key); - $self->{$key} = []; my $query = - qq|SELECT c.cp_id, c.cp_cv_id, c.cp_name, c.cp_givenname, c.cp_abteilung | . - qq|FROM contacts c | . + qq|SELECT cp_id, cp_cv_id, cp_name, cp_givenname, cp_abteilung | . + qq|FROM contacts | . qq|WHERE cp_cv_id = ? | . - qq|ORDER BY lower(c.cp_name)|; - my $sth = $dbh->prepare($query); - $sth->execute($id) || $self->dberror($query . " ($id)"); + qq|ORDER BY lower(cp_name)|; - my $i = 0; - while (my $ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{$key} }, $ref; - $i++; - } + $self->{$key} = selectall_hashref_query($self, $dbh, $query, $id); - if ($i == 0) { - push @{ $self->{$key} }, { { "", "", "", "", "", "" } }; - } - $sth->finish; $main::lxdebug->leave_sub(); } @@ -1521,16 +1437,9 @@ sub _get_projects { qq|FROM project | . $where . qq|ORDER BY lower(projectnumber)|; - my $sth = $dbh->prepare($query); - $sth->execute(@values) || - $self->dberror($query . " (" . join(", ", @values) . ")"); - $self->{$key} = []; - while (my $ref = $sth->fetchrow_hashref(NAME_lc)) { - push(@{ $self->{$key} }, $ref); - } + $self->{$key} = selectall_hashref_query($self, $dbh, $query, @values); - $sth->finish; $main::lxdebug->leave_sub(); } @@ -1540,20 +1449,14 @@ sub _get_shipto { my ($self, $dbh, $vc_id, $key) = @_; $key = "all_shipto" unless ($key); - $self->{$key} = []; # get shipping addresses my $query = - qq|SELECT s.shipto_id,s.shiptoname,s.shiptodepartment_1 | . - qq|FROM shipto s | . - qq|WHERE s.trans_id = ?|; - my $sth = $dbh->prepare($query); - $sth->execute($vc_id) || $self->dberror($query . " ($vc_id)"); + qq|SELECT shipto_id, shiptoname, shiptodepartment_1 | . + qq|FROM shipto | . + qq|WHERE trans_id = ?|; - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push(@{ $self->{$key} }, $ref); - } - $sth->finish; + $self->{$key} = selectall_hashref_query($self, $dbh, $query, $vc_id); $main::lxdebug->leave_sub(); } @@ -1564,16 +1467,10 @@ sub _get_printers { my ($self, $dbh, $key) = @_; $key = "all_printers" unless ($key); - $self->{$key} = []; my $query = qq|SELECT id, printer_description, printer_command FROM printers|; - my $sth = $dbh->prepare($query); - $sth->execute() || $self->dberror($query); - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push(@{ $self->{$key} }, $ref); - } - $sth->finish; + $self->{$key} = selectall_hashref_query($self, $dbh, $query); $main::lxdebug->leave_sub(); } @@ -1585,7 +1482,6 @@ sub _get_charts { $key = $params->{key}; $key = "all_charts" unless ($key); - $self->{$key} = []; my $transdate = quote_db_date($params->{transdate}); @@ -1598,13 +1494,7 @@ sub _get_charts { qq| ORDER BY startdate DESC LIMIT 1)) | . qq|ORDER BY c.accno|; - my $sth = $dbh->prepare($query); - $sth->execute() || $self->dberror($query); - - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push(@{ $self->{$key} }, $ref); - } - $sth->finish; + $self->{$key} = selectall_hashref_query($self, $dbh, $query); $main::lxdebug->leave_sub(); } @@ -1615,17 +1505,10 @@ sub _get_taxcharts { my ($self, $dbh, $key) = @_; $key = "all_taxcharts" unless ($key); - $self->{$key} = []; my $query = qq|SELECT * FROM tax ORDER BY taxkey|; - my $sth = $dbh->prepare($query); - $sth->execute() || $self->dberror($query); - - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push(@{ $self->{$key} }, $ref); - } - $sth->finish; + $self->{$key} = selectall_hashref_query($self, $dbh, $query); $main::lxdebug->leave_sub(); } @@ -1714,47 +1597,43 @@ sub get_name { # connect to database my $dbh = $self->dbconnect($myconfig); - my $name = $self->like(lc $self->{$table}); - my $customernumber = $self->like(lc $self->{customernumber}); + $table = $table eq "customer" ? "customer" : "vendor"; + my $arap = $self->{arap} eq "ar" ? "ar" : "ap"; - if ($self->{customernumber} ne "") { - $query = qq~SELECT c.id, c.name, - c.street || ' ' || c.zipcode || ' ' || c.city || ' ' || c.country AS address - FROM $table c - WHERE (lower(c.customernumber) LIKE '$customernumber') AND (not c.obsolete) - ORDER BY c.name~; - } else { - $query = qq~SELECT c.id, c.name, - c.street || ' ' || c.zipcode || ' ' || c.city || ' ' || c.country AS address - FROM $table c - WHERE (lower(c.name) LIKE '$name') AND (not c.obsolete) - ORDER BY c.name~; - } + my ($query, @values); - if ($self->{openinvoices}) { - $query = qq~SELECT DISTINCT c.id, c.name, - c.street || ' ' || c.zipcode || ' ' || c.city || ' ' || c.country AS address - FROM $self->{arap} a - JOIN $table c ON (a.${table}_id = c.id) - WHERE NOT a.amount = a.paid - AND lower(c.name) LIKE '$name' - ORDER BY c.name~; - } - my $sth = $dbh->prepare($query); - - $sth->execute || $self->dberror($query); + if (!$self->{openinvoices}) { + my $where; + if ($self->{customernumber} ne "") { + $where = qq|(vc.customernumber ILIKE ?)|; + push(@values, '%' . $self->{customernumber} . '%'); + } else { + $where = qq|(vc.name ILIKE ?)|; + push(@values, '%' . $self->{$table} . '%'); + } - my $i = 0; - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push(@{ $self->{name_list} }, $ref); - $i++; + $query = + qq~SELECT vc.id, vc.name, + vc.street || ' ' || vc.zipcode || ' ' || vc.city || ' ' || vc.country AS address + FROM $table vc + WHERE $where AND (NOT vc.obsolete) + ORDER BY vc.name~; + } else { + $query = + qq~SELECT DISTINCT vc.id, vc.name, + vc.street || ' ' || vc.zipcode || ' ' || vc.city || ' ' || vc.country AS address + FROM $arap a + JOIN $table vc ON (a.${table}_id = vc.id) + WHERE NOT (a.amount = a.paid) AND (vc.name ILIKE ?) + ORDER BY vc.name~; + push(@values, '%' . $self->{$table} . '%'); } - $sth->finish; - $dbh->disconnect; + + $self->{name_list} = selectall_hashref_query($self, $dbh, $query, @values); $main::lxdebug->leave_sub(); - return $i; + return scalar(@{ $self->{name_list} }); } # the selection sub is used in the AR, AP, IS, IR and OE module @@ -1767,26 +1646,17 @@ sub all_vc { my $ref; my $dbh = $self->dbconnect($myconfig); + $table = $table eq "customer" ? "customer" : "vendor"; + my $query = qq|SELECT count(*) FROM $table|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - my ($count) = $sth->fetchrow_array; - $sth->finish; + my ($count) = selectrow_query($self, $dbh, $query); # build selection list if ($count < $myconfig->{vclimit}) { $query = qq|SELECT id, name, salesman_id - FROM $table WHERE not obsolete - ORDER BY name|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{"all_$table"} }, $ref; - } - - $sth->finish; - + FROM $table WHERE NOT obsolete + ORDER BY name|; + $self->{"all_$table"} = selectall_hashref_query($self, $dbh, $query); } # get self @@ -1794,21 +1664,14 @@ sub all_vc { # setup sales contacts $query = qq|SELECT e.id, e.name - FROM employee e - WHERE e.sales = '1' - AND NOT e.id = $self->{employee_id}|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{all_employees} }, $ref; - } - $sth->finish; + FROM employee e + WHERE (e.sales = '1') AND (NOT e.id = ?)|; + $self->{all_employees} = selectall_hashref_query($self, $dbh, $query, $self->{employee_id}); # this is for self - push @{ $self->{all_employees} }, - { id => $self->{employee_id}, - name => $self->{employee} }; + push(@{ $self->{all_employees} }, + { id => $self->{employee_id}, + name => $self->{employee} }); # sort the whole thing @{ $self->{all_employees} } = @@ -1817,62 +1680,42 @@ sub all_vc { if ($module eq 'AR') { # prepare query for departments - $query = qq|SELECT d.id, d.description - FROM department d - WHERE d.role = 'P' - ORDER BY 2|; + $query = qq|SELECT id, description + FROM department + WHERE role = 'P' + ORDER BY description|; } else { - $query = qq|SELECT d.id, d.description - FROM department d - ORDER BY 2|; + $query = qq|SELECT id, description + FROM department + ORDER BY description|; } - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{all_departments} }, $ref; - } - $sth->finish; + $self->{all_departments} = selectall_hashref_query($self, $dbh, $query); # get languages $query = qq|SELECT id, description FROM language - ORDER BY 1|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); + ORDER BY id|; - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{languages} }, $ref; - } - $sth->finish; + $self->{languages} = selectall_hashref_query($self, $dbh, $query); # get printer $query = qq|SELECT printer_description, id FROM printers - ORDER BY 1|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{printers} }, $ref; - } - $sth->finish; + ORDER BY printer_description|; + $self->{printers} = selectall_hashref_query($self, $dbh, $query); # get payment terms $query = qq|SELECT id, description FROM payment_terms ORDER BY sortkey|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{payment_terms} }, $ref; - } - $sth->finish; + $self->{payment_terms} = selectall_hashref_query($self, $dbh, $query); + $dbh->disconnect; + $main::lxdebug->leave_sub(); } @@ -1880,59 +1723,34 @@ sub language_payment { $main::lxdebug->enter_sub(); my ($self, $myconfig) = @_; - undef $self->{languages}; - undef $self->{payment_terms}; - undef $self->{printers}; - my $ref; my $dbh = $self->dbconnect($myconfig); # get languages my $query = qq|SELECT id, description - FROM language - ORDER BY 1|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); + FROM language + ORDER BY id|; - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{languages} }, $ref; - } - $sth->finish; + $self->{languages} = selectall_hashref_query($self, $dbh, $query); # get printer $query = qq|SELECT printer_description, id FROM printers - ORDER BY 1|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); + ORDER BY printer_description|; - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{printers} }, $ref; - } - $sth->finish; + $self->{printers} = selectall_hashref_query($self, $dbh, $query); # get payment terms $query = qq|SELECT id, description FROM payment_terms ORDER BY sortkey|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - while ($ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{payment_terms} }, $ref; - } - $sth->finish; + $self->{payment_terms} = selectall_hashref_query($self, $dbh, $query); # get buchungsgruppen $query = qq|SELECT id, description FROM buchungsgruppen|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - $self->{BUCHUNGSGRUPPEN} = []; - while (my $ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{BUCHUNGSGRUPPEN} }, $ref; - } - $sth->finish; + $self->{BUCHUNGSGRUPPEN} = selectall_hashref_query($self, $dbh, $query); $dbh->disconnect; $main::lxdebug->leave_sub(); @@ -1944,26 +1762,20 @@ sub all_departments { my ($self, $myconfig, $table) = @_; - my $dbh = $self->dbconnect($myconfig); - my $where = "1 = 1"; + my $dbh = $self->dbconnect($myconfig); + my $where; - if (defined $table) { - if ($table eq 'customer') { - $where = " d.role = 'P'"; - } + if ($table eq 'customer') { + $where = "WHERE role = 'P' "; } - my $query = qq|SELECT d.id, d.description - FROM department d - WHERE $where - ORDER BY 2|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); + my $query = qq|SELECT id, description + FROM department + $where + ORDER BY description|; + $self->{all_departments} = selectall_hashref_query($self, $dbh, $query); - while (my $ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{all_departments} }, $ref; - } - $sth->finish; + delete($self->{all_departments}) unless (@{ $self->{all_departments} }); $dbh->disconnect; @@ -1975,10 +1787,20 @@ sub create_links { my ($self, $module, $myconfig, $table) = @_; + my ($fld, $arap); + if ($table eq "customer") { + $fld = "buy"; + $arap = "ar"; + } else { + $table = "vendor"; + $fld = "sell"; + $arap = "ap"; + } + $self->all_vc($myconfig, $table, $module); # get last customers or vendors - my ($query, $sth); + my ($query, $sth, $ref); my $dbh = $self->dbconnect($myconfig); my %xkeyref = (); @@ -1987,35 +1809,35 @@ sub create_links { my $transdate = "current_date"; if ($self->{transdate}) { - $transdate = qq|'$self->{transdate}'|; + $transdate = $dbh->quote($self->{transdate}); } - + # now get the account numbers $query = qq|SELECT c.accno, c.description, c.link, c.taxkey_id, tk.tax_id FROM chart c, taxkeys tk - WHERE c.link LIKE '%$module%' AND c.id=tk.chart_id AND tk.id = - (SELECT id FROM taxkeys where taxkeys.chart_id = c.id AND startdate <= $transdate ORDER BY startdate desc LIMIT 1) + WHERE (c.link LIKE ?) AND (c.id = tk.chart_id) AND tk.id = + (SELECT id FROM taxkeys WHERE (taxkeys.chart_id = c.id) AND (startdate <= $transdate) ORDER BY startdate DESC LIMIT 1) ORDER BY c.accno|; - + $sth = $dbh->prepare($query); - do_statement($form, $sth, $query); + do_statement($form, $sth, $query, '%' . $module . '%'); $self->{accounts} = ""; - while (my $ref = $sth->fetchrow_hashref(NAME_lc)) { - + while ($ref = $sth->fetchrow_hashref(NAME_lc)) { + foreach my $key (split(/:/, $ref->{link})) { if ($key =~ /$module/) { - + # cross reference for keys $xkeyref{ $ref->{accno} } = $key; - + push @{ $self->{"${module}_links"}{$key} }, { accno => $ref->{accno}, description => $ref->{description}, taxkey => $ref->{taxkey_id}, tax_id => $ref->{tax_id} }; - + $self->{accounts} .= "$ref->{accno} " unless $key =~ /tax/; } } @@ -2032,80 +1854,64 @@ sub create_links { if (($module eq "AP") || ($module eq "AR")) { # get tax rates and description - $query = qq| SELECT * FROM tax t|; + $query = qq|SELECT * FROM tax|; $self->{TAX} = selectall_hashref_query($form, $dbh, $query); } if ($self->{id}) { - my $arap = ($table eq 'customer') ? 'ar' : 'ap'; - - $query = qq|SELECT a.cp_id, a.invnumber, a.transdate, - a.${table}_id, a.datepaid, a.duedate, a.ordnumber, - a.taxincluded, a.curr AS currency, a.notes, a.intnotes, - c.name AS $table, a.department_id, d.description AS department, - a.amount AS oldinvtotal, a.paid AS oldtotalpaid, - a.employee_id, e.name AS employee, a.gldate, a.type - FROM $arap a - JOIN $table c ON (a.${table}_id = c.id) - LEFT JOIN employee e ON (e.id = a.employee_id) - LEFT JOIN department d ON (d.id = a.department_id) - WHERE a.id = $self->{id}|; - $sth = $dbh->prepare($query); - do_statement($form, $sth, $query); + $query = + qq|SELECT + a.cp_id, a.invnumber, a.transdate, a.${table}_id, a.datepaid, + a.duedate, a.ordnumber, a.taxincluded, a.curr AS currency, a.notes, + a.intnotes, a.department_id, a.amount AS oldinvtotal, + a.paid AS oldtotalpaid, a.employee_id, a.gldate, a.type, + c.name AS $table, + d.description AS department, + e.name AS employee + FROM $arap a + JOIN $table c ON (a.${table}_id = c.id) + LEFT JOIN employee e ON (e.id = a.employee_id) + LEFT JOIN department d ON (d.id = a.department_id) + WHERE a.id = ?|; + $ref = selectfirst_hashref_query($self, $dbh, $query, $self->{id}); - $ref = $sth->fetchrow_hashref(NAME_lc); foreach $key (keys %$ref) { $self->{$key} = $ref->{$key}; } - $sth->finish; - my $transdate = "current_date"; if ($self->{transdate}) { - $transdate = qq|'$self->{transdate}'|; + $transdate = $dbh->quote($self->{transdate}); } - + # now get the account numbers $query = qq| - SELECT - c.accno, - c.description, - c.link, - c.taxkey_id, - tk.tax_id - FROM chart c - LEFT JOIN taxkeys tk ON (tk.chart_id = c.id) - WHERE - c.link LIKE ? - AND - (tk.chart_id = c.id AND NOT c.link like '%_tax%') - OR (NOT tk.chart_id = c.id AND c.link like '%_tax%') - AND - tk.id = ( SELECT id from taxkeys - WHERE taxkeys.chart_id = c.id - AND startdate <= ? - ORDER BY startdate desc LIMIT 1 - ) - ORDER BY c.accno|; - + SELECT + c.accno, c.description, c.link, c.taxkey_id, + tk.tax_id + FROM chart c + LEFT JOIN taxkeys tk ON (tk.chart_id = c.id) + WHERE (c.link LIKE ?) AND (tk.chart_id = c.id) AND NOT (c.link LIKE '%_tax%') + ORDER BY c.accno|; + $sth = $dbh->prepare($query); - do_statement($form, $sth, $query, "%$module%", $transdate); - + do_statement($form, $sth, $query, "%" . $module . "%"); + $self->{accounts} = ""; - while (my $ref = $sth->fetchrow_hashref(NAME_lc)) { - + while ($ref = $sth->fetchrow_hashref(NAME_lc)) { + foreach my $key (split(/:/, $ref->{link})) { if ($key =~ /$module/) { - + # cross reference for keys $xkeyref{ $ref->{accno} } = $key; - + push @{ $self->{"${module}_links"}{$key} }, { accno => $ref->{accno}, description => $ref->{description}, taxkey => $ref->{taxkey_id}, tax_id => $ref->{tax_id} }; - + $self->{accounts} .= "$ref->{accno} " unless $key =~ /tax/; } } @@ -2113,31 +1919,38 @@ sub create_links { # get amounts from individual entries - $query = qq|SELECT c.accno, c.description, a.source, a.amount, a.memo, - a.transdate, a.cleared, a.project_id, p.projectnumber, a.taxkey, t.rate, t.id - FROM acc_trans a - JOIN chart c ON (c.id = a.chart_id) - LEFT JOIN project p ON (p.id = a.project_id) - LEFT JOIN tax t ON (t.id=(SELECT tk.tax_id from taxkeys tk WHERE (tk.taxkey_id=a.taxkey) AND ((CASE WHEN a.chart_id IN (SELECT chart_id FROM taxkeys WHERE taxkey_id=a.taxkey) THEN tk.chart_id=a.chart_id ELSE 1=1 END) OR (c.link='%tax%')) AND startdate <=a.transdate ORDER BY startdate DESC LIMIT 1)) - WHERE a.trans_id = $self->{id} - AND a.fx_transaction = '0' - ORDER BY a.oid,a.transdate|; + $query = + qq|SELECT + c.accno, c.description, + a.source, a.amount, a.memo, a.transdate, a.cleared, a.project_id, a.taxkey, + p.projectnumber, + t.rate, t.id + FROM acc_trans a + LEFT JOIN chart c ON (c.id = a.chart_id) + LEFT JOIN project p ON (p.id = a.project_id) + LEFT JOIN tax t ON (t.id= (SELECT tk.tax_id FROM taxkeys tk + WHERE (tk.taxkey_id=a.taxkey) AND + ((CASE WHEN a.chart_id IN (SELECT chart_id FROM taxkeys WHERE taxkey_id = a.taxkey) + THEN tk.chart_id = a.chart_id + ELSE 1 = 1 + END) + OR (c.link='%tax%')) AND + (startdate <= a.transdate) ORDER BY startdate DESC LIMIT 1)) + WHERE a.trans_id = ? + AND a.fx_transaction = '0' + ORDER BY a.oid, a.transdate|; $sth = $dbh->prepare($query); - do_statement($form, $sth, $query); - - my $fld = ($table eq 'customer') ? 'buy' : 'sell'; + do_statement($form, $sth, $query, $self->{id}); # get exchangerate for currency $self->{exchangerate} = - $self->get_exchangerate($dbh, $self->{currency}, $self->{transdate}, - $fld); + $self->get_exchangerate($dbh, $self->{currency}, $self->{transdate}, $fld); my $index = 0; # store amounts in {acc_trans}{$key} for multiple accounts while (my $ref = $sth->fetchrow_hashref(NAME_lc)) { $ref->{exchangerate} = - $self->get_exchangerate($dbh, $self->{currency}, $ref->{transdate}, - $fld); + $self->get_exchangerate($dbh, $self->{currency}, $ref->{transdate}, $fld); if (!($xkeyref{ $ref->{accno} } =~ /tax/)) { $index++; } @@ -2150,35 +1963,26 @@ sub create_links { } $sth->finish; - $query = qq|SELECT d.curr AS currencies, d.closedto, d.revtrans, - (SELECT c.accno FROM chart c - WHERE d.fxgain_accno_id = c.id) AS fxgain_accno, - (SELECT c.accno FROM chart c - WHERE d.fxloss_accno_id = c.id) AS fxloss_accno - FROM defaults d|; - $sth = $dbh->prepare($query); - do_statement($form, $sth, $query); - - $ref = $sth->fetchrow_hashref(NAME_lc); + $query = + qq|SELECT + d.curr AS currencies, d.closedto, d.revtrans, + (SELECT c.accno FROM chart c WHERE d.fxgain_accno_id = c.id) AS fxgain_accno, + (SELECT c.accno FROM chart c WHERE d.fxloss_accno_id = c.id) AS fxloss_accno + FROM defaults d|; + $ref = selectfirst_hashref_query($self, $dbh, $query); map { $self->{$_} = $ref->{$_} } keys %$ref; - $sth->finish; } else { # get date - $query = qq|SELECT current_date AS transdate, - d.curr AS currencies, d.closedto, d.revtrans, - (SELECT c.accno FROM chart c - WHERE d.fxgain_accno_id = c.id) AS fxgain_accno, - (SELECT c.accno FROM chart c - WHERE d.fxloss_accno_id = c.id) AS fxloss_accno - FROM defaults d|; - $sth = $dbh->prepare($query); - do_statement($form, $sth, $query); - - $ref = $sth->fetchrow_hashref(NAME_lc); + $query = + qq|SELECT + current_date AS transdate, d.curr AS currencies, d.closedto, d.revtrans, + (SELECT c.accno FROM chart c WHERE d.fxgain_accno_id = c.id) AS fxgain_accno, + (SELECT c.accno FROM chart c WHERE d.fxloss_accno_id = c.id) AS fxloss_accno + FROM defaults d|; + $ref = selectfirst_hashref_query($self, $dbh, $query); map { $self->{$_} = $ref->{$_} } keys %$ref; - $sth->finish; if ($self->{"$self->{vc}_id"}) { @@ -2189,19 +1993,14 @@ sub create_links { $self->lastname_used($dbh, $myconfig, $table, $module); - my $fld = ($table eq 'customer') ? 'buy' : 'sell'; - # get exchangerate for currency $self->{exchangerate} = - $self->get_exchangerate($dbh, $self->{currency}, $self->{transdate}, - $fld); + $self->get_exchangerate($dbh, $self->{currency}, $self->{transdate}, $fld); } } - $sth->finish; - $dbh->disconnect; $main::lxdebug->leave_sub(); @@ -2213,6 +2012,7 @@ sub lastname_used { my ($self, $dbh, $myconfig, $table, $module) = @_; my $arap = ($table eq 'customer') ? "ar" : "ap"; + $table = $table eq "customer" ? "customer" : "vendor"; my $where = "1 = 1"; if ($self->{type} =~ /_order/) { @@ -2225,29 +2025,22 @@ sub lastname_used { } my $query = qq|SELECT MAX(id) FROM $arap - WHERE $where - AND ${table}_id > 0|; - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - my ($trans_id) = $sth->fetchrow_array; - $sth->finish; + WHERE $where AND ${table}_id > 0|; + my ($trans_id) = selectrow_query($self, $dbh, $query); $trans_id *= 1; - $query = qq|SELECT ct.name, a.curr, a.${table}_id, - current_date + ct.terms AS duedate, a.department_id, - d.description AS department - FROM $arap a - JOIN $table ct ON (a.${table}_id = ct.id) - LEFT JOIN department d ON (a.department_id = d.id) - WHERE a.id = $trans_id|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); - - ($self->{$table}, $self->{currency}, $self->{"${table}_id"}, - $self->{duedate}, $self->{department_id}, $self->{department}) - = $sth->fetchrow_array; - $sth->finish; + $query = + qq|SELECT + a.curr, a.${table}_id, a.department_id, + d.description AS department, + ct.name, current_date + ct.terms AS duedate + FROM $arap a + LEFT JOIN $table ct ON (a.${table}_id = ct.id) + LEFT JOIN department d ON (a.department_id = d.id) + WHERE a.id = ?|; + ($self->{currency}, $self->{"${table}_id"}, $self->{department_id}, + $self->{department}, $self->{$table}, $self->{duedate}) + = selectrow_query($self, $dbh, $query, $trans_id); $main::lxdebug->leave_sub(); } @@ -2258,26 +2051,19 @@ sub current_date { my ($self, $myconfig, $thisdate, $days) = @_; my $dbh = $self->dbconnect($myconfig); - my ($sth, $query); + my $query; $days *= 1; if ($thisdate) { my $dateformat = $myconfig->{dateformat}; $dateformat .= "yy" if $myconfig->{dateformat} !~ /^y/; - - $query = qq|SELECT to_date('$thisdate', '$dateformat') + $days AS thisdate - FROM defaults|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); + $thisdate = $dbh->quote($thisdate); + $query = qq|SELECT to_date($thisdate, '$dateformat') + $days AS thisdate|; } else { - $query = qq|SELECT current_date AS thisdate - FROM defaults|; - $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); + $query = qq|SELECT current_date AS thisdate|; } - ($thisdate) = $sth->fetchrow_array; - $sth->finish; + ($thisdate) = selectrow_query($self, $dbh, $query); $dbh->disconnect; @@ -2339,47 +2125,45 @@ sub update_status { my $dbh = $self->dbconnect_noauto($myconfig); my $query = qq|DELETE FROM status - WHERE formname = '$self->{formname}' - AND trans_id = ?|; - my $sth = $dbh->prepare($query) || $self->dberror($query); + WHERE (formname = ?) AND (trans_id = ?)|; + my $sth = prepare_query($self, $dbh, $query); if ($self->{formname} =~ /(check|receipt)/) { for $i (1 .. $self->{rowcount}) { - $sth->execute($self->{"id_$i"} * 1) || $self->dberror($query); - $sth->finish; + do_statement($self, $sth, $query, $self->{formname}, $self->{"id_$i"} * 1); } } else { - $sth->execute($self->{id}) || $self->dberror($query); - $sth->finish; + do_statement($self, $sth, $query, $self->{formname}, $self->{id}); } + $sth->finish(); my $printed = ($self->{printed} =~ /$self->{formname}/) ? "1" : "0"; my $emailed = ($self->{emailed} =~ /$self->{formname}/) ? "1" : "0"; my %queued = split / /, $self->{queued}; + my @values; if ($self->{formname} =~ /(check|receipt)/) { # this is a check or receipt, add one entry for each lineitem my ($accno) = split /--/, $self->{account}; - $query = qq|INSERT INTO status (trans_id, printed, spoolfile, formname, - chart_id) VALUES (?, '$printed', - '$queued{$self->{formname}}', '$self->{prinform}', - (SELECT c.id FROM chart c WHERE c.accno = '$accno'))|; - $sth = $dbh->prepare($query) || $self->dberror($query); + $query = qq|INSERT INTO status (trans_id, printed, spoolfile, formname, chart_id) + VALUES (?, ?, ?, ?, (SELECT c.id FROM chart c WHERE c.accno = ?))|; + @values = ($printed, $queued{$self->{formname}}, $self->{prinform}, $accno); + $sth = prepare_query($self, $dbh, $query); for $i (1 .. $self->{rowcount}) { if ($self->{"checked_$i"}) { - $sth->execute($self->{"id_$i"}) || $self->dberror($query); - $sth->finish; + do_statement($self, $sth, $query, $self->{"id_$i"}, @values); } } + $sth->finish(); + } else { - $query = qq|INSERT INTO status (trans_id, printed, emailed, - spoolfile, formname) - VALUES ($self->{id}, '$printed', '$emailed', - '$queued{$self->{formname}}', '$self->{formname}')|; - $dbh->do($query) || $self->dberror($query); + $query = qq|INSERT INTO status (trans_id, printed, emailed, spoolfile, formname) + VALUES (?, ?, ?, ?, ?)|; + do_query($self, $dbh, $query, $self->{id}, $printed, $emailed, + $queued{$self->{formname}}, $self->{formname}); } $dbh->commit; @@ -2388,83 +2172,6 @@ sub update_status { $main::lxdebug->leave_sub(); } -#--- 4 locale ---# -# $main::locale->text('SAVED') -# $main::locale->text('DELETED') -# $main::locale->text('ADDED') -# $main::locale->text('PAYMENT POSTED') -# $main::locale->text('POSTED') -# $main::locale->text('POSTED AS NEW') -# $main::locale->text('ELSE') -# $main::locale->text('SAVED FOR DUNNING') -# $main::locale->text('DUNNING STARTED') -# $main::locale->text('PRINTED') -# $main::locale->text('MAILED') -# $main::locale->text('SCREENED') -# $main::locale->text('invoice') -# $main::locale->text('proforma') -# $main::locale->text('sales_order') -# $main::locale->text('packing_list') -# $main::locale->text('pick_list') -# $main::locale->text('purchase_order') -# $main::locale->text('bin_list') -# $main::locale->text('sales_quotation') -# $main::locale->text('request_quotation') - -sub save_history { - $main::lxdebug->enter_sub(); - - my $self = shift(); - my $dbh = shift(); - - if(!exists $self->{employee_id}) { - &get_employee($self, $dbh); - } - - my $query = - qq|INSERT INTO history_erp (trans_id, employee_id, addition, what_done) | . - qq|VALUES (?, ?, ?, ?)|; - my @values = (conv_i($self->{id}), conv_i($self->{employee_id}), - $self->{addition}, $self->{what_done}); - do_query($self, $dbh, $query, @values); - - $main::lxdebug->leave_sub(); -} - -sub get_history { - $main::lxdebug->enter_sub(); - - my $self = shift(); - my $dbh = shift(); - my $trans_id = shift(); - my $restriction = shift(); - my @tempArray; - my $i = 0; - if ($trans_id ne "") { - my $query = - qq|SELECT h.employee_id, h.itime::timestamp(0) AS itime, h.addition, h.what_done, emp.name | . - qq|FROM history_erp h | . - qq|LEFT JOIN employee emp | . - qq|ON emp.id = h.employee_id | . - qq|WHERE trans_id = ? | - . $restriction; - - my $sth = $dbh->prepare($query) || $self->dberror($query); - - $sth->execute($trans_id) || $self->dberror("$query ($trans_id)"); - - while(my $hash_ref = $sth->fetchrow_hashref()) { - $hash_ref->{addition} = $main::locale->text($hash_ref->{addition}); - $hash_ref->{what_done} = $main::locale->text($hash_ref->{what_done}); - $tempArray[$i++] = $hash_ref; - } - $main::lxdebug->leave_sub() and return \@tempArray - if ($i > 0 && $tempArray[0] ne ""); - } - $main::lxdebug->leave_sub(); - return 0; -} - sub save_status { $main::lxdebug->enter_sub(); @@ -2475,10 +2182,9 @@ sub save_status { my $formnames = $self->{printed}; my $emailforms = $self->{emailed}; - $query = qq|DELETE FROM status - WHERE formname = '$self->{formname}' - AND trans_id = $self->{id}|; - $dbh->do($query) || $self->dberror($query); + my $query = qq|DELETE FROM status + WHERE (formname = ?) AND (trans_id = ?)|; + do_query($self, $dbh, $query, $self->{formname}, $self->{id}); # this only applies to the forms # checks and receipts are posted when printed or queued @@ -2490,11 +2196,9 @@ sub save_status { $printed = ($self->{printed} =~ /$self->{formname}/) ? "1" : "0"; $emailed = ($self->{emailed} =~ /$self->{formname}/) ? "1" : "0"; - $query = qq|INSERT INTO status (trans_id, printed, emailed, - spoolfile, formname) - VALUES ($self->{id}, '$printed', '$emailed', - '$queued{$formname}', '$formname')|; - $dbh->do($query) || $self->dberror($query); + $query = qq|INSERT INTO status (trans_id, printed, emailed, spoolfile, formname) + VALUES (?, ?, ?, ?, ?)|; + do_query($self, $dbh, $query, $self->{id}, $printed, $emailed, $queued{$formname}, $formname); $formnames =~ s/$self->{formname}//; $emailforms =~ s/$self->{formname}//; @@ -2515,13 +2219,89 @@ sub save_status { $emailed = ($emailforms =~ /$self->{formname}/) ? "1" : "0"; $query = qq|INSERT INTO status (trans_id, printed, emailed, formname) - VALUES ($self->{id}, '$printed', '$emailed', '$formname')|; - $dbh->do($query) || $self->dberror($query); + VALUES (?, ?, ?, ?)|; + do_query($self, $dbh, $query, $self->{id}, $printed, $emailed, $formname); } $main::lxdebug->leave_sub(); } +#--- 4 locale ---# +# $main::locale->text('SAVED') +# $main::locale->text('DELETED') +# $main::locale->text('ADDED') +# $main::locale->text('PAYMENT POSTED') +# $main::locale->text('POSTED') +# $main::locale->text('POSTED AS NEW') +# $main::locale->text('ELSE') +# $main::locale->text('SAVED FOR DUNNING') +# $main::locale->text('DUNNING STARTED') +# $main::locale->text('PRINTED') +# $main::locale->text('MAILED') +# $main::locale->text('SCREENED') +# $main::locale->text('invoice') +# $main::locale->text('proforma') +# $main::locale->text('sales_order') +# $main::locale->text('packing_list') +# $main::locale->text('pick_list') +# $main::locale->text('purchase_order') +# $main::locale->text('bin_list') +# $main::locale->text('sales_quotation') +# $main::locale->text('request_quotation') + +sub save_history { + $main::lxdebug->enter_sub(); + + my $self = shift(); + my $dbh = shift(); + + if(!exists $self->{employee_id}) { + &get_employee($self, $dbh); + } + + my $query = + qq|INSERT INTO history_erp (trans_id, employee_id, addition, what_done) | . + qq|VALUES (?, ?, ?, ?)|; + my @values = (conv_i($self->{id}), conv_i($self->{employee_id}), + $self->{addition}, $self->{what_done}); + do_query($self, $dbh, $query, @values); + + $main::lxdebug->leave_sub(); +} + +sub get_history { + $main::lxdebug->enter_sub(); + + my $self = shift(); + my $dbh = shift(); + my $trans_id = shift(); + my $restriction = shift(); + my @tempArray; + my $i = 0; + if ($trans_id ne "") { + my $query = + qq|SELECT h.employee_id, h.itime::timestamp(0) AS itime, h.addition, h.what_done, emp.name | . + qq|FROM history_erp h | . + qq|LEFT JOIN employee emp ON (emp.id = h.employee_id) | . + qq|WHERE trans_id = ? | + . $restriction; + + my $sth = $dbh->prepare($query) || $self->dberror($query); + + $sth->execute($trans_id) || $self->dberror("$query ($trans_id)"); + + while(my $hash_ref = $sth->fetchrow_hashref()) { + $hash_ref->{addition} = $main::locale->text($hash_ref->{addition}); + $hash_ref->{what_done} = $main::locale->text($hash_ref->{what_done}); + $tempArray[$i++] = $hash_ref; + } + $main::lxdebug->leave_sub() and return \@tempArray + if ($i > 0 && $tempArray[0] ne ""); + } + $main::lxdebug->leave_sub(); + return 0; +} + sub update_defaults { $main::lxdebug->enter_sub(); @@ -2542,9 +2322,8 @@ sub update_defaults { $var++; - $query = qq|UPDATE defaults - SET $fld = '$var'|; - $dbh->do($query) || $self->dberror($query); + $query = qq|UPDATE defaults SET $fld = ?|; + do_query($self, $dbh, $query, $var); if (!$provided_dbh) { $dbh->commit; @@ -2568,18 +2347,17 @@ sub update_business { $dbh = $self->dbconnect_noauto($myconfig); } my $query = - qq|SELECT customernumberinit FROM business WHERE id=$business_id FOR UPDATE|; - my $sth = $dbh->prepare($query); + qq|SELECT customernumberinit FROM business + WHERE id = ? FOR UPDATE|; + my ($var) = selectrow_query($self, $dbh, $query, $business_id); - $sth->execute || $self->dberror($query); - my ($var) = $sth->fetchrow_array; - $sth->finish; if ($var ne "") { $var++; } $query = qq|UPDATE business - SET customernumberinit = '$var' WHERE id=$business_id|; - $dbh->do($query) || $self->dberror($query); + SET customernumberinit = ? + WHERE id = ?|; + do_query($self, $dbh, $query, $var, $business_id); if (!$provided_dbh) { $dbh->commit; @@ -2600,27 +2378,23 @@ sub get_partsgroup { my $query = qq|SELECT DISTINCT pg.id, pg.partsgroup FROM partsgroup pg - JOIN parts p ON (p.partsgroup_id = pg.id)|; + JOIN parts p ON (p.partsgroup_id = pg.id) |; + my @values; if ($p->{searchitems} eq 'part') { - $query .= qq| - WHERE p.inventory_accno_id > 0|; + $query .= qq|WHERE p.inventory_accno_id > 0|; } if ($p->{searchitems} eq 'service') { - $query .= qq| - WHERE p.inventory_accno_id IS NULL|; + $query .= qq|WHERE p.inventory_accno_id IS NULL|; } if ($p->{searchitems} eq 'assembly') { - $query .= qq| - WHERE p.assembly = '1'|; + $query .= qq|WHERE p.assembly = '1'|; } if ($p->{searchitems} eq 'labor') { - $query .= qq| - WHERE p.inventory_accno_id > 0 AND p.income_accno_id IS NULL|; + $query .= qq|WHERE (p.inventory_accno_id > 0) AND (p.income_accno_id IS NULL)|; } - $query .= qq| - ORDER BY partsgroup|; + $query .= qq|ORDER BY partsgroup|; if ($p->{all}) { $query = qq|SELECT id, partsgroup FROM partsgroup @@ -2629,21 +2403,16 @@ sub get_partsgroup { if ($p->{language_code}) { $query = qq|SELECT DISTINCT pg.id, pg.partsgroup, - t.description AS translation + t.description AS translation FROM partsgroup pg - JOIN parts p ON (p.partsgroup_id = pg.id) - LEFT JOIN translation t ON (t.trans_id = pg.id AND t.language_code = '$p->{language_code}') - ORDER BY translation|; + JOIN parts p ON (p.partsgroup_id = pg.id) + LEFT JOIN translation t ON ((t.trans_id = pg.id) AND (t.language_code = ?)) + ORDER BY translation|; + @values = ($p->{language_code}); } - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); + $self->{all_partsgroups} = selectall_hashref_query($self, $dbh, $query, @values); - $self->{all_partsgroup} = (); - while (my $ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{all_partsgroup} }, $ref; - } - $sth->finish; $dbh->disconnect; $main::lxdebug->leave_sub(); } @@ -2658,119 +2427,20 @@ sub get_pricegroup { my $query = qq|SELECT p.id, p.pricegroup FROM pricegroup p|; - $query .= qq| - ORDER BY pricegroup|; + $query .= qq| ORDER BY pricegroup|; if ($p->{all}) { $query = qq|SELECT id, pricegroup FROM pricegroup ORDER BY pricegroup|; } - my $sth = $dbh->prepare($query); - $sth->execute || $self->dberror($query); + $self->{all_pricegroup} = selectall_hashref_query($self, $dbh, $query); - $self->{all_pricegroup} = (); - while (my $ref = $sth->fetchrow_hashref(NAME_lc)) { - push @{ $self->{all_pricegroup} }, $ref; - } - $sth->finish; $dbh->disconnect; $main::lxdebug->leave_sub(); } -sub audittrail { - my ($self, $dbh, $myconfig, $audittrail) = @_; - - # table, $reference, $formname, $action, $id, $transdate) = @_; - - my $query; - my $rv; - my $disconnect; - - if (!$dbh) { - $dbh = $self->dbconnect($myconfig); - $disconnect = 1; - } - - # if we have an id add audittrail, otherwise get a new timestamp - - if ($audittrail->{id}) { - - $query = qq|SELECT audittrail FROM defaults|; - - if ($dbh->selectrow_array($query)) { - my ($null, $employee_id) = $self->get_employee($dbh); - - if ($self->{audittrail} && !$myconfig) { - chop $self->{audittrail}; - - my @a = split /\|/, $self->{audittrail}; - my %newtrail = (); - my $key; - my $i; - my @flds = qw(tablename reference formname action transdate); - - # put into hash and remove dups - while (@a) { - $key = "$a[2]$a[3]"; - $i = 0; - $newtrail{$key} = { map { $_ => $a[$i++] } @flds }; - splice @a, 0, 5; - } - - $query = qq|INSERT INTO audittrail (trans_id, tablename, reference, - formname, action, employee_id, transdate) - VALUES ($audittrail->{id}, ?, ?, - ?, ?, $employee_id, ?)|; - my $sth = $dbh->prepare($query) || $self->dberror($query); - - foreach $key ( - sort { - $newtrail{$a}{transdate} cmp $newtrail{$b}{transdate} - } keys %newtrail - ) { - $i = 1; - for (@flds) { $sth->bind_param($i++, $newtrail{$key}{$_}) } - - $sth->execute || $self->dberror; - $sth->finish; - } - } - - if ($audittrail->{transdate}) { - $query = qq|INSERT INTO audittrail (trans_id, tablename, reference, - formname, action, employee_id, transdate) VALUES ( - $audittrail->{id}, '$audittrail->{tablename}', | - . $dbh->quote($audittrail->{reference}) . qq|, - '$audittrail->{formname}', '$audittrail->{action}', - $employee_id, '$audittrail->{transdate}')|; - } else { - $query = qq|INSERT INTO audittrail (trans_id, tablename, reference, - formname, action, employee_id) VALUES ($audittrail->{id}, - '$audittrail->{tablename}', | - . $dbh->quote($audittrail->{reference}) . qq|, - '$audittrail->{formname}', '$audittrail->{action}', - $employee_id)|; - } - $dbh->do($query); - } - } else { - - $query = qq|SELECT current_timestamp FROM defaults|; - my ($timestamp) = $dbh->selectrow_array($query); - - $rv = - "$audittrail->{tablename}|$audittrail->{reference}|$audittrail->{formname}|$audittrail->{action}|$timestamp|"; - } - - $dbh->disconnect if $disconnect; - - $rv; - -} - - sub all_years { # usage $form->all_years($myconfig, [$dbh]) # return list of all years where bookings found @@ -2779,33 +2449,32 @@ sub all_years { $main::lxdebug->enter_sub(); my ($self, $myconfig, $dbh) = @_; - + my $disconnect = 0; if (! $dbh) { $dbh = $self->dbconnect($myconfig); $disconnect = 1; } - + # get years my $query = qq|SELECT (SELECT MIN(transdate) FROM acc_trans), - (SELECT MAX(transdate) FROM acc_trans) - FROM defaults|; - my ($startdate, $enddate) = $dbh->selectrow_array($query); + (SELECT MAX(transdate) FROM acc_trans)|; + my ($startdate, $enddate) = selectrow_query($self, $dbh, $query); if ($myconfig->{dateformat} =~ /^yy/) { ($startdate) = split /\W/, $startdate; ($enddate) = split /\W/, $enddate; - } else { + } else { (@_) = split /\W/, $startdate; $startdate = $_[2]; (@_) = split /\W/, $enddate; - $enddate = $_[2]; + $enddate = $_[2]; } my @all_years; $startdate = substr($startdate,0,4); $enddate = substr($enddate,0,4); - + while ($enddate >= $startdate) { push @all_years, $enddate--; } diff --git a/SL/GL.pm b/SL/GL.pm index 13a12ffd6..cd0d995b5 100644 --- a/SL/GL.pm +++ b/SL/GL.pm @@ -211,14 +211,6 @@ sub post_transaction { } } - my %audittrail = (tablename => 'gl', - reference => $form->{reference}, - formname => 'transaction', - action => 'posted', - id => $form->{id}); - - # $form->audittrail($dbh, "", \%audittrail); - # commit and redirect my $rc = $dbh->commit; $dbh->disconnect; diff --git a/SL/IC.pm b/SL/IC.pm index a2703b64f..a4b17f844 100644 --- a/SL/IC.pm +++ b/SL/IC.pm @@ -795,7 +795,7 @@ sub adjust_inventory { $sth->finish; # update assembly - my $rc = $form->update_balance($dbh, "parts", "onhand", qq|id = $id|, $qty); + my $rc = $form->update_balance($dbh, "parts", "onhand", qq|id = ?|, $qty, $id); $main::lxdebug->leave_sub(); diff --git a/SL/IR.pm b/SL/IR.pm index 9a6ca9ddc..f51ce4a4b 100644 --- a/SL/IR.pm +++ b/SL/IR.pm @@ -224,9 +224,8 @@ sub post_invoice { $dbh->do($query) || $form->dberror($query); - $form->update_balance($dbh, "parts", "onhand", - qq|id = $form->{"id_$i"}|, - $baseqty) + $form->update_balance($dbh, "parts", "onhand", qq|id = ?|, + $baseqty, $form->{"id_$i"}) unless $form->{shipped}; # check if we sold the item already and diff --git a/SL/IS.pm b/SL/IS.pm index 6523d243b..402df0d28 100644 --- a/SL/IS.pm +++ b/SL/IS.pm @@ -711,9 +711,8 @@ sub post_invoice { $sth->execute || $form->dberror($query); if ($sth->fetchrow_array) { - $form->update_balance($dbh, "parts", "onhand", - qq|id = $form->{"id_$i"}|, - $baseqty * -1) + $form->update_balance($dbh, "parts", "onhand", qq|id = ?|, + $baseqty * -1, $form->{"id_$i"}) unless $form->{shipped}; } $sth->finish; @@ -721,9 +720,8 @@ sub post_invoice { # record assembly item as allocated &process_assembly($dbh, $form, $form->{"id_$i"}, $baseqty); } else { - $form->update_balance($dbh, "parts", "onhand", - qq|id = $form->{"id_$i"}|, - $baseqty * -1) + $form->update_balance($dbh, "parts", "onhand", qq|id = ?|, + $baseqty * -1, $form->{"id_$i"}) unless $form->{shipped}; $allocated = &cogs($dbh, $form, $form->{"id_$i"}, $baseqty, $basefactor, $i); diff --git a/SL/LICENSES.pm b/SL/LICENSES.pm index ce1e799d6..7d5f4ba36 100644 --- a/SL/LICENSES.pm +++ b/SL/LICENSES.pm @@ -69,8 +69,8 @@ sub save_license { $sth->finish(); if ($form->{own_product}) { - $form->update_balance($dbh, "parts", "onhand", qq|id = $form->{parts_id}|, - 1); + $form->update_balance($dbh, "parts", "onhand", qq|id = ?|, + 1, $form->{parts_id}); } $dbh->disconnect(); diff --git a/bin/mozilla/arap.pl b/bin/mozilla/arap.pl index b17b061da..f2e4e822b 100644 --- a/bin/mozilla/arap.pl +++ b/bin/mozilla/arap.pl @@ -47,6 +47,8 @@ sub check_name { my ($name) = @_; + $name = $name eq "customer" ? "customer" : "vendor"; + my ($new_name, $new_id) = split /--/, $form->{$name}; my $i = 0; # if we use a selection -- 2.20.1