1 #=====================================================================
4 # Based on SQL-Ledger Version 2.1.9
5 # Web http://www.lx-office.org
7 #=====================================================================
8 # SQL-Ledger Accounting
11 # Author: Dieter Simader
12 # Email: dsimader@sql-ledger.org
13 # Web: http://www.sql-ledger.org
17 # This program is free software; you can redistribute it and/or modify
18 # it under the terms of the GNU General Public License as published by
19 # the Free Software Foundation; either version 2 of the License, or
20 # (at your option) any later version.
22 # This program is distributed in the hope that it will be useful,
23 # but WITHOUT ANY WARRANTY; without even the implied warranty of
24 # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
25 # GNU General Public License for more details.
26 # You should have received a copy of the GNU General Public License
27 # along with this program; if not, write to the Free Software
28 # Foundation, Inc., 675 Mass Ave, Cambridge, MA 02139, USA.
29 #======================================================================
31 # Inventory Control backend
33 #======================================================================
38 use List::MoreUtils qw(all);
44 $main::lxdebug->enter_sub();
46 my ($self, $myconfig, $form) = @_;
49 my $dbh = $form->dbconnect($myconfig);
55 c1.accno AS inventory_accno,
56 c2.accno AS income_accno,
57 c3.accno AS expense_accno,
60 LEFT JOIN chart c1 ON (p.inventory_accno_id = c1.id)
61 LEFT JOIN chart c2 ON (p.income_accno_id = c2.id)
62 LEFT JOIN chart c3 ON (p.expense_accno_id = c3.id)
63 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
65 my $ref = selectfirst_hashref_query($form, $dbh, $query, conv_i($form->{id}));
67 # copy to $form variables
68 map { $form->{$_} = $ref->{$_} } (keys %{$ref});
72 my %oid = ('Pg' => 'a.oid',
73 'Oracle' => 'a.rowid');
75 # part or service item
76 $form->{item} = ($form->{inventory_accno}) ? 'part' : 'service';
77 if ($form->{assembly}) {
78 $form->{item} = 'assembly';
80 # retrieve assembly items
82 qq|SELECT p.id, p.partnumber, p.description,
83 p.sellprice, p.lastcost, p.weight, a.qty, a.bom, p.unit,
84 pg.partsgroup, p.price_factor_id, pfac.factor AS price_factor
86 JOIN assembly a ON (a.parts_id = p.id)
87 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
88 LEFT JOIN price_factors pfac ON pfac.id = p.price_factor_id
90 ORDER BY $oid{$myconfig->{dbdriver}}|;
91 $sth = prepare_execute_query($form, $dbh, $query, conv_i($form->{id}));
93 $form->{assembly_rows} = 0;
94 while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
95 $form->{assembly_rows}++;
96 foreach my $key (keys %{$ref}) {
97 $form->{"${key}_$form->{assembly_rows}"} = $ref->{$key};
104 # setup accno hash for <option checked> {amount} is used in create_links
105 $form->{amount}{IC} = $form->{inventory_accno};
106 $form->{amount}{IC_income} = $form->{income_accno};
107 $form->{amount}{IC_sale} = $form->{income_accno};
108 $form->{amount}{IC_expense} = $form->{expense_accno};
109 $form->{amount}{IC_cogs} = $form->{expense_accno};
111 my @pricegroups = ();
112 my @pricegroups_not_used = ();
116 qq|SELECT p.parts_id, p.pricegroup_id, p.price,
117 (SELECT pg.pricegroup
119 WHERE pg.id = p.pricegroup_id) AS pricegroup
122 ORDER BY pricegroup|;
123 $sth = prepare_execute_query($form, $dbh, $query, conv_i($form->{id}));
127 while (($form->{"klass_$i"}, $form->{"pricegroup_id_$i"},
128 $form->{"price_$i"}, $form->{"pricegroup_$i"})
129 = $sth->fetchrow_array()) {
130 push @pricegroups, $form->{"pricegroup_id_$i"};
137 $query = qq|SELECT id, pricegroup FROM pricegroup|;
138 $form->{PRICEGROUPS} = selectall_hashref_query($form, $dbh, $query);
140 #find not used pricegroups
141 while ($tmp = pop(@{ $form->{PRICEGROUPS} })) {
143 foreach my $item (@pricegroups) {
144 if ($item eq $tmp->{id}) {
149 push(@pricegroups_not_used, $tmp) unless ($in_use);
152 # if not used pricegroups are avaible
153 if (@pricegroups_not_used) {
155 foreach $name (@pricegroups_not_used) {
156 $form->{"klass_$i"} = "$name->{id}";
157 $form->{"pricegroup_id_$i"} = "$name->{id}";
158 $form->{"pricegroup_$i"} = "$name->{pricegroup}";
164 $form->{price_rows} = $i - 1;
166 unless ($form->{item} eq 'service') {
169 if ($form->{makemodel}) {
170 $query = qq|SELECT m.make, m.model FROM makemodel m | .
171 qq|WHERE m.parts_id = ?|;
172 @values = ($form->{id});
173 $sth = $dbh->prepare($query);
174 $sth->execute(@values) || $form->dberror("$query (" . join(', ', @values) . ")");
177 while (($form->{"make_$i"}, $form->{"model_$i"}) = $sth->fetchrow_array)
182 $form->{makemodel_rows} = $i - 1;
188 $form->{language_values} = "";
189 $query = qq|SELECT language_id, translation, longdescription
192 my $trq = prepare_execute_query($form, $dbh, $query, conv_i($form->{id}));
193 while (my $tr = $trq->fetchrow_hashref(NAME_lc)) {
194 $form->{language_values} .= "---+++---" . join('--++--', @{$tr}{qw(language_id translation longdescription)});
198 # now get accno for taxes
201 FROM chart c, partstax pt
202 WHERE (pt.chart_id = c.id) AND (pt.parts_id = ?)|;
203 $sth = prepare_execute_query($form, $dbh, $query, conv_i($form->{id}));
204 while (($key) = $sth->fetchrow_array) {
205 $form->{amount}{$key} = $key;
211 my @referencing_tables = qw(invoice orderitems inventory rmaitems);
212 my %column_map = ( );
213 my $parts_id = conv_i($form->{id});
215 $form->{orphaned} = 1;
217 foreach my $table (@referencing_tables) {
218 my $column = $column_map{$table} || 'parts_id';
219 $query = qq|SELECT $column FROM $table WHERE $column = ? LIMIT 1|;
220 my ($found) = selectrow_query($form, $dbh, $query, $parts_id);
223 $form->{orphaned} = 0;
228 $form->{"unit_changeable"} = $form->{orphaned};
232 $main::lxdebug->leave_sub();
235 sub get_pricegroups {
236 $main::lxdebug->enter_sub();
238 my ($self, $myconfig, $form) = @_;
240 my $dbh = $form->dbconnect($myconfig);
243 my $query = qq|SELECT id, pricegroup FROM pricegroup|;
244 my $pricegroups = selectall_hashref_query($form, $dbh, $query);
247 foreach $pg (@{ $pricegroups }) {
248 $form->{"klass_$i"} = "$pg->{id}";
249 $form->{"price_$i"} = $form->format_amount($myconfig, $form->{"price_$i"}, -2);
250 $form->{"pricegroup_id_$i"} = "$pg->{id}";
251 $form->{"pricegroup_$i"} = "$pg->{pricegroup}";
256 $form->{price_rows} = $i - 1;
260 $main::lxdebug->leave_sub();
265 sub retrieve_buchungsgruppen {
266 $main::lxdebug->enter_sub();
268 my ($self, $myconfig, $form) = @_;
272 my $dbh = $form->dbconnect($myconfig);
274 # get buchungsgruppen
275 $query = qq|SELECT id, description FROM buchungsgruppen ORDER BY sortkey|;
276 $form->{BUCHUNGSGRUPPEN} = selectall_hashref_query($form, $dbh, $query);
278 $main::lxdebug->leave_sub();
282 $main::lxdebug->enter_sub();
284 my ($self, $myconfig, $form) = @_;
286 # connect to database, turn off AutoCommit
287 my $dbh = $form->dbconnect_noauto($myconfig);
290 # make up a unique handle and store in partnumber field
291 # then retrieve the record based on the unique handle to get the id
292 # replace the partnumber field with the actual variable
293 # add records for makemodel
295 # if there is a $form->{id} then replace the old entry
296 # delete all makemodel entries and add the new ones
298 # undo amount formatting
299 map { $form->{$_} = $form->parse_amount($myconfig, $form->{$_}) }
300 qw(rop weight listprice sellprice gv lastcost);
302 my $makemodel = (($form->{make_1}) || ($form->{model_1})) ? 1 : 0;
304 $form->{assembly} = ($form->{item} eq 'assembly') ? 1 : 0;
308 my $priceupdate = ', priceupdate = current_date';
313 $query = qq|SELECT sellprice, weight FROM parts WHERE id = ?|;
314 my ($sellprice, $weight) = selectrow_query($form, $dbh, $query, conv_i($form->{id}));
316 # if item is part of an assembly adjust all assemblies
317 $query = qq|SELECT id, qty FROM assembly WHERE parts_id = ?|;
318 $sth = prepare_execute_query($form, $dbh, $query, conv_i($form->{id}));
319 while (my ($id, $qty) = $sth->fetchrow_array) {
320 &update_assembly($dbh, $form, $id, $qty, $sellprice * 1, $weight * 1);
324 if ($form->{item} ne 'service') {
325 # delete makemodel records
326 do_query($form, $dbh, qq|DELETE FROM makemodel WHERE parts_id = ?|, conv_i($form->{id}));
329 if ($form->{item} eq 'assembly') {
330 # delete assembly records
331 do_query($form, $dbh, qq|DELETE FROM assembly WHERE id = ?|, conv_i($form->{id}));
335 do_query($form, $dbh, qq|DELETE FROM partstax WHERE parts_id = ?|, conv_i($form->{id}));
337 # delete translations
338 do_query($form, $dbh, qq|DELETE FROM translation WHERE parts_id = ?|, conv_i($form->{id}));
340 # Check whether or not the prices have changed. If they haven't
341 # then 'priceupdate' should not be updated.
342 my $previous_values = selectfirst_hashref_query($form, $dbh, qq|SELECT * FROM parts WHERE id = ?|, conv_i($form->{id})) || {};
343 $priceupdate = '' if (all { $previous_values->{$_} == $form->{$_} } qw(sellprice lastcost listprice));
346 my ($count) = selectrow_query($form, $dbh, qq|SELECT COUNT(*) FROM parts WHERE partnumber = ?|, $form->{partnumber});
348 $main::lxdebug->leave_sub();
352 ($form->{id}) = selectrow_query($form, $dbh, qq|SELECT nextval('id')|);
353 do_query($form, $dbh, qq|INSERT INTO parts (id, partnumber) VALUES (?, '')|, $form->{id});
355 $form->{orphaned} = 1;
356 if ($form->{partnumber} eq "" && $form->{"item"} eq "service") {
357 $form->{partnumber} = $form->update_defaults($myconfig, "servicenumber");
359 if ($form->{partnumber} eq "" && $form->{"item"} ne "service") {
360 $form->{partnumber} = $form->update_defaults($myconfig, "articlenumber");
364 my $partsgroup_id = 0;
366 if ($form->{partsgroup}) {
367 ($partsgroup, $partsgroup_id) = split(/--/, $form->{partsgroup});
370 my ($subq_inventory, $subq_expense, $subq_income);
371 if ($form->{"item"} eq "part") {
373 qq|(SELECT bg.inventory_accno_id
374 FROM buchungsgruppen bg
375 WHERE bg.id = | . conv_i($form->{"buchungsgruppen_id"}, 'NULL') . qq|)|;
377 $subq_inventory = "NULL";
380 if ($form->{"item"} ne "assembly") {
382 qq|(SELECT bg.expense_accno_id_0
383 FROM buchungsgruppen bg
384 WHERE bg.id = | . conv_i($form->{"buchungsgruppen_id"}, 'NULL') . qq|)|;
386 $subq_expense = "NULL";
405 buchungsgruppen_id = ?,
407 inventory_accno_id = $subq_inventory,
408 income_accno_id = (SELECT bg.income_accno_id_0 FROM buchungsgruppen bg WHERE bg.id = ?),
409 expense_accno_id = $subq_expense,
417 not_discountable = ?,
423 @values = ($form->{partnumber},
424 $form->{description},
425 $makemodel ? 't' : 'f',
426 $form->{assembly} ? 't' : 'f',
436 conv_i($form->{buchungsgruppen_id}),
437 conv_i($form->{payment_id}),
438 conv_i($form->{buchungsgruppen_id}),
439 $form->{obsolete} ? 't' : 'f',
442 $form->{shop} ? 't' : 'f',
446 $form->{not_discountable} ? 't' : 'f',
448 conv_i($partsgroup_id),
449 conv_i($form->{price_factor_id}),
452 do_query($form, $dbh, $query, @values);
454 # delete translation records
455 do_query($form, $dbh, qq|DELETE FROM translation WHERE parts_id = ?|, conv_i($form->{id}));
457 if ($form->{language_values} ne "") {
458 foreach $item (split(/---\+\+\+---/, $form->{language_values})) {
459 my ($language_id, $translation, $longdescription) = split(/--\+\+--/, $item);
460 if ($translation ne "") {
461 $query = qq|INSERT into translation (parts_id, language_id, translation, longdescription)
462 VALUES ( ?, ?, ?, ? )|;
463 @values = (conv_i($form->{id}), conv_i($language_id), $translation, $longdescription);
464 do_query($form, $dbh, $query, @values);
469 # delete price records
470 do_query($form, $dbh, qq|DELETE FROM prices WHERE parts_id = ?|, conv_i($form->{id}));
472 # insert price records only if different to sellprice
473 for my $i (1 .. $form->{price_rows}) {
474 my $price = $form->parse_amount($myconfig, $form->{"price_$i"});
476 $form->{"price_$i"} = $form->{sellprice};
480 || $form->{"klass_$i"}
481 || $form->{"pricegroup_id_$i"})
482 and $price != $form->{sellprice}
484 #$klass = $form->parse_amount($myconfig, $form->{"klass_$i"});
485 $query = qq|INSERT INTO prices (parts_id, pricegroup_id, price) | .
487 @values = (conv_i($form->{id}), conv_i($form->{"pricegroup_id_$i"}), $price);
488 do_query($form, $dbh, $query, @values);
492 # insert makemodel records
493 unless ($form->{item} eq 'service') {
494 for my $i (1 .. $form->{makemodel_rows}) {
495 if (($form->{"make_$i"}) || ($form->{"model_$i"})) {
497 $query = qq|INSERT INTO makemodel (parts_id, make, model) | .
498 qq|VALUES (?, ?, ?)|;
499 @values = (conv_i($form->{id}), conv_i($form->{"make_$i"}), $form->{"model_$i"});
501 do_query($form, $dbh, $query, @values);
507 foreach $item (split(/ /, $form->{taxaccounts})) {
508 if ($form->{"IC_tax_$item"}) {
510 qq|INSERT INTO partstax (parts_id, chart_id)
511 VALUES (?, (SELECT id FROM chart WHERE accno = ?))|;
512 @values = (conv_i($form->{id}), $item);
513 do_query($form, $dbh, $query, @values);
517 # add assembly records
518 if ($form->{item} eq 'assembly') {
520 for my $i (1 .. $form->{assembly_rows}) {
521 $form->{"qty_$i"} = $form->parse_amount($myconfig, $form->{"qty_$i"});
523 if ($form->{"qty_$i"} != 0) {
524 $form->{"bom_$i"} *= 1;
525 $query = qq|INSERT INTO assembly (id, parts_id, qty, bom) | .
526 qq|VALUES (?, ?, ?, ?)|;
527 @values = (conv_i($form->{id}), conv_i($form->{"id_$i"}), conv_i($form->{"qty_$i"}), $form->{"bom_$i"} ? 't' : 'f');
528 do_query($form, $dbh, $query, @values);
535 my $shippingdate = "$a[5]-$a[4]-$a[3]";
537 $form->get_employee($dbh);
541 #set expense_accno=inventory_accno if they are different => bilanz
543 ($form->{expense_accno} != $form->{inventory_accno})
544 ? $form->{inventory_accno}
545 : $form->{expense_accno};
547 # get tax rates and description
549 ($form->{vc} eq "customer") ? $form->{income_accno} : $vendor_accno;
551 qq|SELECT c.accno, c.description, t.rate, t.taxnumber
553 WHERE (c.id = t.chart_id) AND (t.taxkey IN (SELECT taxkey_id FROM chart where accno = ?))
555 $stw = prepare_execute_query($form, $dbh, $query, $accno_id);
557 $form->{taxaccount} = "";
558 while ($ptr = $stw->fetchrow_hashref(NAME_lc)) {
559 $form->{taxaccount} .= "$ptr->{accno} ";
560 if (!($form->{taxaccount2} =~ /\Q$ptr->{accno}\E/)) {
561 $form->{"$ptr->{accno}_rate"} = $ptr->{rate};
562 $form->{"$ptr->{accno}_description"} = $ptr->{description};
563 $form->{"$ptr->{accno}_taxnumber"} = $ptr->{taxnumber};
564 $form->{taxaccount2} .= " $ptr->{accno} ";
569 my $rc = $dbh->commit;
572 $main::lxdebug->leave_sub();
577 sub update_assembly {
578 $main::lxdebug->enter_sub();
580 my ($dbh, $form, $id, $qty, $sellprice, $weight) = @_;
582 my $query = qq|SELECT id, qty FROM assembly WHERE parts_id = ?|;
583 my $sth = prepare_execute_query($form, $dbh, $query, conv_i($id));
585 while (my ($pid, $aqty) = $sth->fetchrow_array) {
586 &update_assembly($dbh, $form, $pid, $aqty * $qty, $sellprice, $weight);
591 qq|UPDATE parts SET sellprice = sellprice + ?, weight = weight + ?
593 @values = ($qty * ($form->{sellprice} - $sellprice),
594 $qty * ($form->{weight} - $weight), conv_i($id));
595 do_query($form, $dbh, $query, @values);
597 $main::lxdebug->leave_sub();
600 sub retrieve_assemblies {
601 $main::lxdebug->enter_sub();
603 my ($self, $myconfig, $form) = @_;
605 # connect to database
606 my $dbh = $form->dbconnect($myconfig);
608 my $where = qq|NOT p.obsolete|;
611 if ($form->{partnumber}) {
612 $where .= qq| AND (p.partnumber ILIKE ?)|;
613 push(@values, '%' . $form->{partnumber} . '%');
616 if ($form->{description}) {
617 $where .= qq| AND (p.description ILIKE ?)|;
618 push(@values, '%' . $form->{description} . '%');
621 # retrieve assembly items
623 qq|SELECT p.id, p.partnumber, p.description,
624 p.bin, p.onhand, p.rop,
625 (SELECT sum(p2.inventory_accno_id)
626 FROM parts p2, assembly a
627 WHERE (p2.id = a.parts_id) AND (a.id = p.id)) AS inventory
629 WHERE NOT p.obsolete AND p.assembly $where|;
631 $form->{assembly_items} = selectall_hashref_query($form, $dbh, $query, @values);
635 $main::lxdebug->leave_sub();
639 $main::lxdebug->enter_sub();
641 my ($self, $myconfig, $form) = @_;
642 my @values = (conv_i($form->{id}));
643 # connect to database, turn off AutoCommit
644 my $dbh = $form->dbconnect_noauto($myconfig);
646 my %columns = ( "assembly" => "id", "parts" => "id" );
648 for my $table (qw(prices partstax makemodel inventory assembly license translation parts)) {
649 my $column = defined($columns{$table}) ? $columns{$table} : "parts_id";
650 do_query($form, $dbh, qq|DELETE FROM $table WHERE $column = ?|, @values);
654 my $rc = $dbh->commit;
657 $main::lxdebug->leave_sub();
663 $main::lxdebug->enter_sub();
665 my ($self, $myconfig, $form) = @_;
667 my $i = $form->{assembly_rows};
669 my $where = qq|1 = 1|;
672 my %columns = ("partnumber" => "p", "description" => "p", "partsgroup" => "pg");
674 while (my ($column, $table) = each(%columns)) {
675 next unless ($form->{"${column}_$i"});
676 $where .= qq| AND ${table}.${column} ILIKE ?|;
677 push(@values, '%' . $form->{"${column}_$i"} . '%');
681 $where .= qq| AND NOT (p.id = ?)|;
682 push(@values, conv_i($form->{id}));
686 $where .= qq| ORDER BY p.partnumber|;
688 $where .= qq| ORDER BY p.description|;
691 # connect to database
692 my $dbh = $form->dbconnect($myconfig);
695 qq|SELECT p.id, p.partnumber, p.description, p.sellprice,
696 p.weight, p.onhand, p.unit, pg.partsgroup, p.lastcost,
697 p.price_factor_id, pfac.factor AS price_factor
699 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
700 LEFT JOIN price_factors pfac ON pfac.id = p.price_factor_id
702 $form->{item_list} = selectall_hashref_query($form, $dbh, $query, @values);
706 $main::lxdebug->leave_sub();
711 # Warning, deep magic ahead.
712 # This function gets all parts from the database according to the filters specified
715 # sort revers - sorting field + direction
718 # simple filter strings (every one of those also has a column flag prefixed with 'l_' associated):
719 # partnumber ean description partsgroup microfiche drawing
722 # l_partnumber l_description l_listprice l_sellprice l_lastcost l_priceupdate l_weight l_unit l_bin l_rop l_image l_drawing l_microfiche l_partsgroup
725 # itemstatus = active | onhand | short | obsolete | orphaned
726 # searchitems = part | assembly | service
729 # make model - makemodel
730 # serialnumber transdatefrom transdateto - invoice/orderitems
733 # bought sold onorder ordered rfq quoted - aggreg joins with invoices/orders
734 # l_linetotal l_subtotal - aggreg joins to display totals (complicated) - NOT IMPLEMENTED here, implementation at frontend
735 # l_soldtotal - aggreg join to display total of sold quantity
736 # onhand - as above, but masking the simple itemstatus results (doh!)
737 # short - NOT IMPLEMENTED as form filter, only as itemstatus option
738 # l_serialnumber - belonges to serialnumber filter
739 # l_deliverydate - displays deliverydate is sold etc. flags are active
740 # l_soldtotal - aggreg join to display total of sold quantity, works as long as there's no bullshit in soldtotal
743 # onhand - as above, but masking the simple itemstatus results (doh!)
744 # masking of onhand in bsooqr mode - ToDO: fixme
746 # disabled sanity checks and changes:
747 # - searchitems = assembly will no longer disable bought
748 # - searchitems = service will no longer disable make and model, although services don't have make/model, it doesn't break the query
749 # - itemstatus = orphaned will no longer disable onhand short bought sold onorder ordered rfq quoted transdate[from|to]
750 # - itemstatus = obsolete will no longer disable onhand, short
751 # - allow sorting by ean
752 # - serialnumber filter also works if l_serialnumber isn't ticked
753 # - onhand doesn't get masked by it's oi or invoice counterparts atm. ToDO: fix this
754 # - sorting will now change sorting if the requested sorting column isn't checked and doesn't get checked as a side effect
757 $main::lxdebug->enter_sub();
759 my ($self, $myconfig, $form) = @_;
760 my $dbh = $form->get_standard_dbh($myconfig);
762 $form->{parts} = +{ };
763 $form->{soldtotal} = undef if $form->{l_soldtotal}; # security fix. top100 insists on putting strings in there...
765 my @simple_filters = qw(partnumber ean description partsgroup microfiche drawing onhand);
766 my @makemodel_filters = qw(make model);
767 my @invoice_oi_filters = qw(serialnumber soldtotal);
768 my @apoe_filters = qw(transdate);
769 my @all_columns = (@simple_filters, @makemodel_filters, @apoe_filters, qw(serialnumber));
770 my @simple_l_switches = (@all_columns, qw(listprice sellprice lastcost priceupdate weight unit bin rop image));
771 my @oe_flags = qw(bought sold onorder ordered rfq quoted);
772 my @qsooqr_flags = qw(invnumber ordnumber quonumber trans_id name module);
773 my @deliverydate_flags = qw(deliverydate);
774 # my @other_flags = qw(onhand); # ToDO: implement these
775 # my @inactive_flags = qw(l_subtotal short l_linetotal);
778 partsgroup => 'LEFT JOIN partsgroup pg ON (pg.id = p.partsgroup_id)',
779 makemodel => 'LEFT JOIN makemodel mm ON (mm.parts_id = p.id)',
780 pfac => 'LEFT JOIN price_factors pfac ON (pfac.id = p.price_factor_id)',
783 SELECT parts_id, description, serialnumber, trans_id, unit, sellprice, qty, assemblyitem, 'invoice' AS ioi FROM invoice UNION
784 SELECT parts_id, description, serialnumber, trans_id, unit, sellprice, qty, FALSE AS assemblyitem, 'orderitems' AS ioi FROM orderitems
785 ) AS ioi ON ioi.parts_id = p.id|,
788 SELECT id, transdate, 'ir' AS module, ordnumber, quonumber, invnumber, FALSE AS quotation, NULL AS customer_id, vendor_id, NULL AS deliverydate, 'invoice' AS ioi FROM ap UNION
789 SELECT id, transdate, 'is' AS module, ordnumber, quonumber, invnumber, FALSE AS quotation, customer_id, NULL AS vendor_id, deliverydate, 'invoice' AS ioi FROM ar UNION
790 SELECT id, transdate, 'oe' AS module, ordnumber, quonumber, NULL AS invnumber, quotation, customer_id, vendor_id, NULL AS deliverydate, 'orderitems' AS ioi FROM oe
791 ) AS apoe ON ((ioi.trans_id = apoe.id) AND (ioi.ioi = apoe.ioi))|,
794 SELECT id, name, 'customer' AS cv FROM customer UNION
795 SELECT id, name, 'vendor' AS cv FROM vendor
796 ) AS cv ON cv.id = apoe.customer_id OR cv.id = apoe.vendor_id|,
798 my @join_order = qw(partsgroup makemodel invoice_oi apoe cv pfac);
801 if (($form->{searchitems} eq 'assembly') && $form->{l_lastcost}) {
802 @simple_l_switches = grep { $_ ne 'lastcost' } @simple_l_switches;
805 #===== switches and simple filters ========#
807 my @select_tokens = qw(id factor);
808 my @where_tokens = qw(1=1);
809 my @group_tokens = ();
811 # special case transdate
812 if (grep { $form->{$_} } qw(transdatefrom transdateto)) {
813 $form->{"l_transdate"} = 1;
814 push @select_tokens, 'transdate';
815 for (qw(transdatefrom transdateto)) {
816 next unless $form->{$_};
817 push @where_tokens, sprintf "transdate %s ?", /from$/ ? '>=' : '<=';
818 push @bind_vars, $form->{$_};
822 my %simple_filter_table_prefix = (
826 foreach (@simple_filters, @makemodel_filters, @invoice_oi_filters) {
827 next unless $form->{$_};
828 $form->{"l_$_"} = '1'; # show the column
829 push @where_tokens, "$simple_filter_table_prefix{$_}$_ ILIKE ?";
830 push @bind_vars, "%$form->{$_}%";
833 foreach (@simple_l_switches) {
834 next unless $form->{"l_$_"};
835 push @select_tokens, $_;
838 for ($form->{searchitems}) {
839 push @where_tokens, 'p.inventory_accno_id > 0' if /part/;
840 push @where_tokens, 'p.inventory_accno_id IS NULL' if /service/;
841 push @where_tokens, 'NOT p.assembly' if /service/;
842 push @where_tokens, ' p.assembly' if /assembly/;
845 for ($form->{itemstatus}) {
846 push @where_tokens, 'p.id NOT IN
847 (SELECT DISTINCT parts_id FROM invoice UNION
848 SELECT DISTINCT parts_id FROM assembly UNION
849 SELECT DISTINCT parts_id FROM orderitems)' if /orphaned/;
850 push @where_tokens, 'p.onhand = 0' if /orphaned/;
851 push @where_tokens, 'NOT p.obsolete' if /active/;
852 push @where_tokens, ' p.obsolete', if /obsolete/;
853 push @where_tokens, 'p.onhand > 0', if /onhand/;
854 push @where_tokens, 'p.onhand < p.rop', if /short/;
857 my $q_assembly_lastcost =
858 qq|(SELECT SUM(a_lc.qty * p_lc.lastcost / COALESCE(pfac_lc.factor, 1))
860 LEFT JOIN parts p_lc ON (a_lc.parts_id = p_lc.id)
861 LEFT JOIN price_factors pfac_lc ON (p_lc.price_factor_id = pfac_lc.id)
862 WHERE (a_lc.id = p.id)) AS lastcost|;
864 my @sort_cols = (@simple_filters, qw(id bin priceupdate onhand invnumber ordnumber quonumber name serialnumber soldtotal deliverydate));
865 $form->{sort} = 'id' unless grep { $form->{"l_$_"} } grep { $form->{sort} eq $_ } @sort_cols;
867 my $sort_order = ($form->{revers} ? ' DESC' : ' ASC');
869 # special case: sorting by partnumber
870 # since partnumbers are expected to be prefixed integers, a special sorting is implemented sorting first lexically by prefix and then by suffix.
871 # and yes, that expression is designed to hold that array of regexes only once, so the map is kinda messy, sorry about that.
872 # ToDO: implement proper functional sorting
873 $form->{sort} = join ', ', map { push @select_tokens, $_; ($table_prefix{$_} = "substring(partnumber,'[") . $_ } qw|^[:digit:]]+') [:digit:]]+')::INTEGER|
874 if $form->{sort} eq 'partnumber';
876 my $order_clause = " ORDER BY $form->{sort} $sort_order";
878 my $limit_clause = " LIMIT 100" if $form->{top100};
880 #=== joins and complicated filters ========#
882 my $bsooqr = $form->{bought} || $form->{sold}
883 || $form->{ordered} || $form->{onorder}
884 || $form->{quoted} || $form->{rfq};
887 push @select_tokens, @qsooqr_flags if $bsooqr;
888 push @select_tokens, @deliverydate_flags if $bsooqr && $form->{l_deliverydate};
889 push @select_tokens, $q_assembly_lastcost if ($form->{searchitems} eq 'assembly') && $form->{l_lastcost};
890 push @bsooqr_tokens, q|module = 'ir' AND NOT ioi.assemblyitem| if $form->{bought};
891 push @bsooqr_tokens, q|module = 'is' AND NOT ioi.assemblyitem| if $form->{sold};
892 push @bsooqr_tokens, q|module = 'oe' AND NOT quotation AND cv = 'customer'| if $form->{ordered};
893 push @bsooqr_tokens, q|module = 'oe' AND NOT quotation AND cv = 'vendor'| if $form->{onorder};
894 push @bsooqr_tokens, q|module = 'oe' AND quotation AND cv = 'customer'| if $form->{quoted};
895 push @bsooqr_tokens, q|module = 'oe' AND quotation AND cv = 'vendor'| if $form->{rfq};
896 push @where_tokens, join ' OR ', map { "($_)" } @bsooqr_tokens if $bsooqr;
898 $joins_needed{partsgroup} = 1;
899 $joins_needed{pfac} = 1;
900 $joins_needed{makemodel} = 1 if grep { $form->{$_} || $form->{"l_$_"} } @makemodel_filters;
901 $joins_needed{cv} = 1 if $bsooqr;
902 $joins_needed{apoe} = 1 if $joins_needed{cv} || grep { $form->{$_} || $form->{"l_$_"} } @apoe_filters;
903 $joins_needed{invoice_oi} = 1 if $joins_needed{apoe} || grep { $form->{$_} || $form->{"l_$_"} } @invoice_oi_filters;
905 # special case for description search.
906 # up in the simple filter section the description filter got interpreted as something like: WHERE description ILIKE '%$form->{description}%'
907 # now we'd like to search also for the masked description entered in orderitems and invoice, so...
908 # find the old entries in of @where_tokens and @bind_vars, and adjust them
909 if ($joins_needed{invoice_oi}) {
910 for (my ($wi, $bi) = (0)x2; $wi <= $#where_tokens; $bi++ if $where_tokens[$wi++] =~ /\?/) {
911 next unless $where_tokens[$wi] =~ /^description ILIKE/;
912 splice @where_tokens, $wi, 1, 'p.description ILIKE ? OR ioi.description ILIKE ?';
913 splice @bind_vars, $bi, 0, $bind_vars[$bi];
918 # now the master trick: soldtotal.
919 if ($form->{l_soldtotal}) {
920 push @where_tokens, 'ioi.qty >= 0';
921 push @group_tokens, @select_tokens;
922 map { s/.*\sAS\s+//si } @group_tokens;
923 push @select_tokens, 'SUM(ioi.qty)';
926 #============= build query ================#
930 deliverydate => 'apoe.', serialnumber => 'ioi.',
931 transdate => 'apoe.', trans_id => 'ioi.',
932 module => 'apoe.', name => 'cv.',
933 ordnumber => 'apoe.', make => 'mm.',
934 quonumber => 'apoe.', model => 'mm.',
935 invnumber => 'apoe.', partsgroup => 'pg.',
938 'SUM(ioi.qty)' => ' ',
941 $table_prefix{$q_assembly_lastcost} = ' ';
943 my %renamed_columns = (
944 'factor' => 'price_factor',
945 'SUM(ioi.qty)' => 'soldtotal',
948 map { $table_prefix{$_} = 'ioi.' } qw(description serialnumber qty unit) if $joins_needed{invoice_oi};
949 map { $renamed_columns{$_} = ' AS ' . $renamed_columns{$_} } keys %renamed_columns;
951 my $select_clause = join ', ', map { ($table_prefix{$_} || "p.") . $_ . $renamed_columns{$_} } @select_tokens;
952 my $join_clause = join ' ', @joins{ grep $joins_needed{$_}, @join_order };
953 my $where_clause = join ' AND ', map { "($_)" } @where_tokens;
954 my $group_clause = ' GROUP BY ' . join ', ', map { ($table_prefix{$_} || "p.") . $_ } @group_tokens if scalar @group_tokens;
956 my $query = qq|SELECT DISTINCT $select_clause FROM parts p $join_clause WHERE $where_clause $group_clause $order_clause $limit_clause|;
958 $form->{parts} = selectall_hashref_query($form, $dbh, $query, @bind_vars);
960 map { $_->{onhand} *= 1 } @{ $form->{parts} };
962 # post processing for assembly parts lists (bom)
963 # for each part get the assembly parts and add them into the partlist.
965 if ($form->{searchitems} eq 'assembly' && $form->{bom}) {
967 qq|SELECT p.id, p.partnumber, p.description, a.qty AS onhand,
969 p.sellprice, p.listprice, p.lastcost,
970 p.rop, p.weight, p.priceupdate,
971 p.image, p.drawing, p.microfiche,
974 INNER JOIN assembly a ON (p.id = a.parts_id)
977 $sth = prepare_query($form, $dbh, $query);
979 foreach $item (@{ $form->{parts} }) {
980 push(@assemblies, $item);
981 do_statement($form, $sth, $query, conv_i($item->{id}));
983 while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
984 $ref->{assemblyitem} = 1;
985 map { $ref->{$_} /= $ref->{factor} || 1 } qw(sellprice listprice lastcost);
986 push(@assemblies, $ref);
991 # copy assemblies to $form->{parts}
992 $form->{parts} = \@assemblies;
995 $main::lxdebug->leave_sub();
998 sub _create_filter_for_priceupdate {
999 $main::lxdebug->enter_sub();
1002 my $myconfig = \%main::myconfig;
1003 my $form = $main::form;
1006 my $where = '1 = 1';
1008 foreach my $item (qw(partnumber drawing microfiche make model pg.partsgroup)) {
1010 $column =~ s/.*\.//;
1011 next unless ($form->{$column});
1013 $where .= qq| AND $item ILIKE ?|;
1014 push(@where_values, '%' . $form->{$column} . '%');
1017 foreach my $item (qw(description serialnumber)) {
1018 next unless ($form->{$item});
1020 $where .= qq| AND (${item} ILIKE ?)|;
1021 push(@where_values, '%' . $form->{$item} . '%');
1025 # items which were never bought, sold or on an order
1026 if ($form->{itemstatus} eq 'orphaned') {
1028 qq| AND (p.onhand = 0)
1031 SELECT DISTINCT parts_id FROM invoice
1033 SELECT DISTINCT parts_id FROM assembly
1035 SELECT DISTINCT parts_id FROM orderitems
1038 } elsif ($form->{itemstatus} eq 'active') {
1039 $where .= qq| AND p.obsolete = '0'|;
1041 } elsif ($form->{itemstatus} eq 'obsolete') {
1042 $where .= qq| AND p.obsolete = '1'|;
1044 } elsif ($form->{itemstatus} eq 'onhand') {
1045 $where .= qq| AND p.onhand > 0|;
1047 } elsif ($form->{itemstatus} eq 'short') {
1048 $where .= qq| AND p.onhand < p.rop|;
1052 foreach my $column (qw(make model)) {
1053 next unless ($form->{$colum});
1054 $where .= qq| AND p.id IN (SELECT DISTINCT parts_id FROM makemodel WHERE $column ILIKE ?|;
1055 push(@where_values, '%' . $form->{$column} . '%');
1058 $main::lxdebug->leave_sub();
1060 return ($where, @where_values);
1063 sub get_num_matches_for_priceupdate {
1064 $main::lxdebug->enter_sub();
1068 my $myconfig = \%main::myconfig;
1069 my $form = $main::form;
1071 my $dbh = $params{dbh} || $form->get_standard_dbh($myconfig);
1073 my ($where, @where_values) = $self->_create_filter_for_priceupdate();
1075 my $num_updated = 0;
1078 for my $column (qw(sellprice listprice)) {
1079 next if ($form->{$column} eq "");
1087 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
1089 my ($result) = selectfirst_array_query($from, $dbh, $query, @where_values);
1090 $num_updated += $result if (0 <= $result);
1099 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
1100 WHERE $where) AND (pricegroup_id = ?)|;
1101 my $sth = prepare_query($form, $dbh, $query);
1103 for my $i (1 .. $form->{price_rows}) {
1104 next if ($form->{"price_$i"} eq "");
1106 my ($result) = do_statement($form, $sth, $query, @where_values, conv_i($form->{"pricegroup_id_$i"}));
1107 $num_updated += $result if (0 <= $result);
1111 $main::lxdebug->leave_sub();
1113 return $num_updated;
1117 $main::lxdebug->enter_sub();
1119 my ($self, $myconfig, $form) = @_;
1121 my ($where, @where_values) = $self->_create_filter_for_priceupdate();
1122 my $num_updated = 0;
1124 # connect to database
1125 my $dbh = $form->dbconnect_noauto($myconfig);
1127 for my $column (qw(sellprice listprice)) {
1128 next if ($form->{$column} eq "");
1130 my $value = $form->parse_amount($myconfig, $form->{$column});
1133 if ($form->{"${column}_type"} eq "percent") {
1134 $value = ($value / 100) + 1;
1139 qq|UPDATE parts SET $column = $column $operator ?
1143 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
1145 my $result = do_query($from, $dbh, $query, $value, @where_values);
1146 $num_updated += $result if (0 <= $result);
1150 qq|UPDATE prices SET price = price + ?
1154 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
1155 WHERE $where) AND (pricegroup_id = ?)|;
1156 my $sth_add = prepare_query($form, $dbh, $q_add);
1159 qq|UPDATE prices SET price = price * ?
1163 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
1164 WHERE $where) AND (pricegroup_id = ?)|;
1165 my $sth_multiply = prepare_query($form, $dbh, $q_multiply);
1167 for my $i (1 .. $form->{price_rows}) {
1168 next if ($form->{"price_$i"} eq "");
1170 my $value = $form->parse_amount($myconfig, $form->{"price_$i"});
1173 if ($form->{"pricegroup_type_$i"} eq "percent") {
1174 $result = do_statement($form, $sth_multiply, $q_multiply, ($value / 100) + 1, @where_values, conv_i($form->{"pricegroup_id_$i"}));
1176 $result = do_statement($form, $sth_add, $q_add, $value, @where_values, conv_i($form->{"pricegroup_id_$i"}));
1179 $num_updated += $result if (0 <= $result);
1183 $sth_multiply->finish();
1185 my $rc= $dbh->commit;
1188 $main::lxdebug->leave_sub();
1190 return $num_updated;
1194 $main::lxdebug->enter_sub();
1196 my ($self, $module, $myconfig, $form) = @_;
1198 # connect to database
1199 my $dbh = $form->dbconnect($myconfig);
1201 my @values = ('%' . $module . '%');
1205 qq|SELECT c.accno, c.description, c.link, c.id,
1206 p.inventory_accno_id, p.income_accno_id, p.expense_accno_id
1207 FROM chart c, parts p
1208 WHERE (c.link LIKE ?) AND (p.id = ?)
1210 push(@values, conv_i($form->{id}));
1214 qq|SELECT c.accno, c.description, c.link, c.id,
1215 d.inventory_accno_id, d.income_accno_id, d.expense_accno_id
1216 FROM chart c, defaults d
1221 my $sth = prepare_execute_query($form, $dbh, $query, @values);
1222 while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
1223 foreach my $key (split(/:/, $ref->{link})) {
1224 if ($key =~ /\Q$module\E/) {
1225 if ( ($ref->{id} eq $ref->{inventory_accno_id})
1226 || ($ref->{id} eq $ref->{income_accno_id})
1227 || ($ref->{id} eq $ref->{expense_accno_id})) {
1228 push @{ $form->{"${module}_links"}{$key} },
1229 { accno => $ref->{accno},
1230 description => $ref->{description},
1231 selected => "selected" };
1232 $form->{"${key}_default"} = "$ref->{accno}--$ref->{description}";
1234 push @{ $form->{"${module}_links"}{$key} },
1235 { accno => $ref->{accno},
1236 description => $ref->{description},
1244 # get buchungsgruppen
1245 $form->{BUCHUNGSGRUPPEN} = selectall_hashref_query($form, $dbh, qq|SELECT id, description FROM buchungsgruppen|);
1248 $form->{payment_terms} = selectall_hashref_query($form, $dbh, qq|SELECT id, description FROM payment_terms ORDER BY sortkey|);
1251 ($form->{priceupdate}) = selectrow_query($form, $dbh, qq|SELECT current_date|);
1255 $main::lxdebug->leave_sub();
1258 # get partnumber, description, unit, sellprice and soldtotal with choice through $sortorder for Top100
1260 $main::lxdebug->enter_sub();
1262 my ($self, $myconfig, $form, $sortorder) = @_;
1263 my $dbh = $form->dbconnect($myconfig);
1264 my $order = qq| p.partnumber|;
1265 my $where = qq|1 = 1|;
1268 if ($sortorder eq "all") {
1269 $where .= qq| AND (partnumber ILIKE ?) AND (description ILIKE ?)|;
1270 push(@values, '%' . $form->{partnumber} . '%', '%' . $form->{description} . '%');
1272 } elsif ($sortorder eq "partnumber") {
1273 $where .= qq| AND (partnumber ILIKE ?)|;
1274 push(@values, '%' . $form->{partnumber} . '%');
1276 } elsif ($sortorder eq "description") {
1277 $where .= qq| AND (description ILIKE ?)|;
1278 push(@values, '%' . $form->{description} . '%');
1279 $order = "description";
1284 qq|SELECT id, partnumber, description, unit, sellprice
1286 WHERE $where ORDER BY $order|;
1288 my $sth = prepare_execute_query($form, $dbh, $query, @values);
1291 while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
1292 if (($ref->{partnumber} eq "*") && ($ref->{description} eq "")) {
1297 $form->{"id_$j"} = $ref->{id};
1298 $form->{"partnumber_$j"} = $ref->{partnumber};
1299 $form->{"description_$j"} = $ref->{description};
1300 $form->{"unit_$j"} = $ref->{unit};
1301 $form->{"sellprice_$j"} = $ref->{sellprice};
1302 $form->{"soldtotal_$j"} = get_soldtotal($dbh, $ref->{id});
1308 $main::lxdebug->leave_sub();
1313 # gets sum of sold part with part_id
1315 $main::lxdebug->enter_sub();
1317 my ($dbh, $id) = @_;
1319 my $query = qq|SELECT sum(qty) FROM invoice WHERE parts_id = ?|;
1320 my ($sum) = selectrow_query($form, $dbh, $query, conv_i($id));
1323 $main::lxdebug->leave_sub();
1326 } #end get_soldtotal
1328 sub retrieve_languages {
1329 $main::lxdebug->enter_sub();
1331 my ($self, $myconfig, $form) = @_;
1333 # connect to database
1334 my $dbh = $form->dbconnect($myconfig);
1339 if ($form->{language_values} ne "") {
1341 qq|SELECT l.id, l.description, tr.translation, tr.longdescription
1343 LEFT OUTER JOIN translation tr ON (tr.language_id = l.id) AND (tr.parts_id = ?)
1344 ORDER BY lower(l.description)|;
1345 @values = (conv_i($form->{id}));
1348 $query = qq|SELECT id, description
1350 ORDER BY lower(description)|;
1353 my $languages = selectall_hashref_query($form, $dbh, $query, @values);
1357 $main::lxdebug->leave_sub();
1362 sub follow_account_chain {
1363 $main::lxdebug->enter_sub(2);
1365 my ($self, $form, $dbh, $transdate, $accno_id, $accno) = @_;
1367 my @visited_accno_ids = ($accno_id);
1372 qq|SELECT c.new_chart_id, date($transdate) >= c.valid_from AS is_valid, | .
1375 qq|LEFT JOIN chart cnew ON c.new_chart_id = cnew.id | .
1376 qq|WHERE (c.id = ?) AND NOT c.new_chart_id ISNULL AND (c.new_chart_id > 0)|;
1377 $sth = prepare_query($form, $dbh, $query);
1380 do_statement($form, $sth, $query, $accno_id);
1381 $ref = $sth->fetchrow_hashref();
1382 last unless ($ref && $ref->{"is_valid"} &&
1383 !grep({ $_ == $ref->{"new_chart_id"} } @visited_accno_ids));
1384 $accno_id = $ref->{"new_chart_id"};
1385 $accno = $ref->{"accno"};
1386 push(@visited_accno_ids, $accno_id);
1389 $main::lxdebug->leave_sub(2);
1391 return ($accno_id, $accno);
1394 sub retrieve_accounts {
1395 $main::lxdebug->enter_sub(2);
1397 my ($self, $myconfig, $form, $parts_id, $index) = @_;
1399 my ($query, $sth, $dbh);
1401 $form->{"taxzone_id"} *= 1;
1403 $dbh = $form->get_standard_dbh($myconfig);
1406 if ($form->{type} eq "invoice") {
1407 if (($form->{vc} eq "vendor") || !$form->{deliverydate}) {
1408 $transdate = $form->{invdate};
1410 $transdate = $form->{deliverydate};
1412 } elsif (($form->{type} eq "credit_note") || ($form->{script} eq 'ir.pl')) {
1413 $transdate = $form->{invdate};
1415 $transdate = $form->{transdate};
1418 if ($transdate eq "") {
1419 $transdate = "current_date";
1421 $transdate = $dbh->quote($transdate);
1426 qq| p.inventory_accno_id AS is_part, | .
1427 qq| bg.inventory_accno_id, | .
1428 qq| bg.income_accno_id_$form->{taxzone_id} AS income_accno_id, | .
1429 qq| bg.expense_accno_id_$form->{taxzone_id} AS expense_accno_id, | .
1430 qq| c1.accno AS inventory_accno, | .
1431 qq| c2.accno AS income_accno, | .
1432 qq| c3.accno AS expense_accno | .
1434 qq|LEFT JOIN buchungsgruppen bg ON p.buchungsgruppen_id = bg.id | .
1435 qq|LEFT JOIN chart c1 ON bg.inventory_accno_id = c1.id | .
1436 qq|LEFT JOIN chart c2 ON bg.income_accno_id_$form->{taxzone_id} = c2.id | .
1437 qq|LEFT JOIN chart c3 ON bg.expense_accno_id_$form->{taxzone_id} = c3.id | .
1439 my $ref = selectfirst_hashref_query($form, $dbh, $query, $parts_id);
1441 return $main::lxdebug->leave_sub(2) if (!$ref);
1443 $ref->{"inventory_accno_id"} = undef unless ($ref->{"is_part"});
1446 foreach my $type (qw(inventory income expense)) {
1447 next unless ($ref->{"${type}_accno_id"});
1448 ($accounts{"${type}_accno_id"}, $accounts{"${type}_accno"}) =
1449 $self->follow_account_chain($form, $dbh, $transdate,
1450 $ref->{"${type}_accno_id"},
1451 $ref->{"${type}_accno"});
1454 map({ $form->{"${_}_accno_$index"} = $accounts{"${_}_accno"} }
1455 qw(inventory income expense));
1457 my $inc_exp = $form->{"vc"} eq "customer" ? "income" : "expense";
1458 my $accno_id = $accounts{"${inc_exp}_accno_id"};
1461 qq|SELECT c.accno, t.taxdescription AS description, t.rate, t.taxnumber | .
1463 qq|LEFT JOIN chart c ON c.id = t.chart_id | .
1464 qq|WHERE t.id IN | .
1465 qq| (SELECT tk.tax_id | .
1466 qq| FROM taxkeys tk | .
1467 qq| WHERE tk.chart_id = ? AND startdate <= | . quote_db_date($transdate) .
1468 qq| ORDER BY startdate DESC LIMIT 1) |;
1469 $ref = selectfirst_hashref_query($form, $dbh, $query, $accno_id);
1472 $main::lxdebug->leave_sub(2);
1476 $form->{"taxaccounts_$index"} = $ref->{"accno"};
1477 if ($form->{"taxaccounts"} !~ /$ref->{accno}/) {
1478 $form->{"taxaccounts"} .= "$ref->{accno} ";
1480 map({ $form->{"$ref->{accno}_${_}"} = $ref->{$_}; }
1481 qw(rate description taxnumber));
1483 # $main::lxdebug->message(0, "formvars: rate " . $form->{"$ref->{accno}_rate"} .
1484 # " description " . $form->{"$ref->{accno}_description"} .
1485 # " taxnumber " . $form->{"$ref->{accno}_taxnumber"} .
1486 # " || taxaccounts_$index " . $form->{"taxaccounts_$index"} .
1487 # " || taxaccounts " . $form->{"taxaccounts"});
1489 $main::lxdebug->leave_sub(2);
1492 sub get_basic_part_info {
1493 $main::lxdebug->enter_sub();
1498 Common::check_params(\%params, qw(id));
1500 my @ids = 'ARRAY' eq ref $params{id} ? @{ $params{id} } : ($params{id});
1503 $main::lxdebug->leave_sub();
1507 my $myconfig = \%main::myconfig;
1508 my $form = $main::form;
1510 my $dbh = $form->get_standard_dbh($myconfig);
1512 my $query = qq|SELECT id, partnumber, description, unit FROM parts WHERE id IN (| . join(', ', ('?') x scalar(@ids)) . qq|)|;
1514 my $info = selectall_hashref_query($form, $dbh, $query, map { conv_i($_) } @ids);
1516 if ('' eq ref $params{id}) {
1517 $info = $info->[0] || { };
1519 $main::lxdebug->leave_sub();
1523 my %info_map = map { $_->{id} => $_ } @{ $info };
1525 $main::lxdebug->leave_sub();
1530 sub prepare_parts_for_printing {
1531 $main::lxdebug->enter_sub();
1536 my $myconfig = \%main::myconfig;
1537 my $form = $main::form;
1539 my $dbh = $params{dbh} || $form->get_standard_dbh($myconfig);
1541 my $prefix = $params{prefix} || 'id_';
1542 my $rowcount = defined $params{rowcount} ? $params{rowcount} : $form->{rowcount};
1544 my @part_ids = keys %{ { map { $_ => 1 } grep { $_ } map { $form->{"${prefix}${_}"} } (1 .. $rowcount) } };
1547 $main::lxdebug->leave_sub();
1551 my $placeholders = join ', ', ('?') x scalar(@part_ids);
1552 my $query = qq|SELECT mm.parts_id, mm.model, v.name AS make
1554 LEFT JOIN vendor v ON (mm.make = cast (v.id as text))
1555 WHERE mm.parts_id IN ($placeholders)|;
1559 my $sth = prepare_execute_query($form, $dbh, $query, @part_ids);
1561 while (my $ref = $sth->fetchrow_hashref()) {
1562 $makemodel{$ref->{parts_id}} ||= [];
1563 push @{ $makemodel{$ref->{parts_id}} }, $ref;
1568 my @columns = qw(ean image microfiche drawing weight);
1570 $query = qq|SELECT id, | . join(', ', @columns) . qq|
1572 WHERE id IN ($placeholders)|;
1574 my %data = selectall_as_map($form, $dbh, $query, 'id', \@columns, @part_ids);
1576 map { $form->{TEMPLATE_ARRAYS}{$_} = [] } (qw(make model), @columns);
1578 foreach my $i (1 .. $rowcount) {
1579 my $id = $form->{"${prefix}${i}"};
1583 foreach (@columns) {
1584 push @{ $form->{TEMPLATE_ARRAYS}{$_} }, $data{$id}->{$_};
1587 push @{ $form->{TEMPLATE_ARRAYS}{make} }, [];
1588 push @{ $form->{TEMPLATE_ARRAYS}{model} }, [];
1590 next if (!$makemodel{$id});
1592 foreach my $ref (@{ $makemodel{$id} }) {
1593 map { push @{ $form->{TEMPLATE_ARRAYS}{$_}->[-1] }, $ref->{$_} } qw(make model);
1597 $main::lxdebug->leave_sub();