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 any uniq);
48 $main::lxdebug->enter_sub();
50 my ($self, $myconfig, $form) = @_;
53 my $dbh = $form->dbconnect($myconfig);
59 c1.accno AS inventory_accno,
60 c2.accno AS income_accno,
61 c3.accno AS expense_accno,
64 LEFT JOIN chart c1 ON (p.inventory_accno_id = c1.id)
65 LEFT JOIN chart c2 ON (p.income_accno_id = c2.id)
66 LEFT JOIN chart c3 ON (p.expense_accno_id = c3.id)
67 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
69 my $ref = selectfirst_hashref_query($form, $dbh, $query, conv_i($form->{id}));
71 # copy to $form variables
72 map { $form->{$_} = $ref->{$_} } (keys %{$ref});
76 # part or service item
77 $form->{item} = ($form->{inventory_accno}) ? 'part' : 'service';
78 if ($form->{assembly}) {
79 $form->{item} = 'assembly';
81 # retrieve assembly items
83 qq|SELECT p.id, p.partnumber, p.description,
84 p.sellprice, p.lastcost, p.weight, a.qty, a.bom, p.unit,
85 pg.partsgroup, p.price_factor_id, pfac.factor AS price_factor
87 JOIN assembly a ON (a.parts_id = p.id)
88 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
89 LEFT JOIN price_factors pfac ON pfac.id = p.price_factor_id
92 $sth = prepare_execute_query($form, $dbh, $query, conv_i($form->{id}));
94 $form->{assembly_rows} = 0;
95 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
96 $form->{assembly_rows}++;
97 foreach my $key (keys %{$ref}) {
98 $form->{"${key}_$form->{assembly_rows}"} = $ref->{$key};
105 # setup accno hash for <option checked> {amount} is used in create_links
106 $form->{amount}{IC} = $form->{inventory_accno};
107 $form->{amount}{IC_income} = $form->{income_accno};
108 $form->{amount}{IC_sale} = $form->{income_accno};
109 $form->{amount}{IC_expense} = $form->{expense_accno};
110 $form->{amount}{IC_cogs} = $form->{expense_accno};
112 my @pricegroups = ();
113 my @pricegroups_not_used = ();
117 qq|SELECT p.parts_id, p.pricegroup_id, p.price,
118 (SELECT pg.pricegroup
120 WHERE pg.id = p.pricegroup_id) AS pricegroup
123 ORDER BY pricegroup|;
124 $sth = prepare_execute_query($form, $dbh, $query, conv_i($form->{id}));
128 while (($form->{"klass_$i"}, $form->{"pricegroup_id_$i"},
129 $form->{"price_$i"}, $form->{"pricegroup_$i"})
130 = $sth->fetchrow_array()) {
131 push @pricegroups, $form->{"pricegroup_id_$i"};
138 $query = qq|SELECT id, pricegroup FROM pricegroup|;
139 $form->{PRICEGROUPS} = selectall_hashref_query($form, $dbh, $query);
141 #find not used pricegroups
142 while (my $tmp = pop(@{ $form->{PRICEGROUPS} })) {
144 foreach my $item (@pricegroups) {
145 if ($item eq $tmp->{id}) {
150 push(@pricegroups_not_used, $tmp) unless ($in_use);
153 # if not used pricegroups are avaible
154 if (@pricegroups_not_used) {
156 foreach my $name (@pricegroups_not_used) {
157 $form->{"klass_$i"} = "$name->{id}";
158 $form->{"pricegroup_id_$i"} = "$name->{id}";
159 $form->{"pricegroup_$i"} = "$name->{pricegroup}";
165 $form->{price_rows} = $i - 1;
168 if ($form->{makemodel}) {
170 $query = qq|SELECT m.make, m.model,m.lastcost,m.lastcost,m.lastupdate,m.sortorder FROM makemodel m | .
171 qq|WHERE m.parts_id = ? order by m.sortorder asc|;
172 my @values = ($form->{id});
173 $sth = $dbh->prepare($query);
174 $sth->execute(@values) || $form->dberror("$query (" . join(', ', @values) . ")");
178 while (($form->{"make_$i"}, $form->{"model_$i"}, $form->{"old_lastcost_$i"},
179 $form->{"lastcost_$i"}, $form->{"lastupdate_$i"}, $form->{"sortorder_$i"}) = $sth->fetchrow_array)
184 $form->{makemodel_rows} = $i - 1;
189 $form->{language_values} = "";
190 $query = qq|SELECT language_id, translation, longdescription
193 my $trq = prepare_execute_query($form, $dbh, $query, conv_i($form->{id}));
194 while (my $tr = $trq->fetchrow_hashref("NAME_lc")) {
195 $form->{language_values} .= "---+++---" . join('--++--', @{$tr}{qw(language_id translation longdescription)});
199 # now get accno for taxes
202 FROM chart c, partstax pt
203 WHERE (pt.chart_id = c.id) AND (pt.parts_id = ?)|;
204 $sth = prepare_execute_query($form, $dbh, $query, conv_i($form->{id}));
205 while (my ($key) = $sth->fetchrow_array) {
206 $form->{amount}{$key} = $key;
212 my @referencing_tables = qw(invoice orderitems inventory rmaitems);
213 my %column_map = ( );
214 my $parts_id = conv_i($form->{id});
216 $form->{orphaned} = 1;
218 foreach my $table (@referencing_tables) {
219 my $column = $column_map{$table} || 'parts_id';
220 $query = qq|SELECT $column FROM $table WHERE $column = ? LIMIT 1|;
221 my ($found) = selectrow_query($form, $dbh, $query, $parts_id);
224 $form->{orphaned} = 0;
229 $form->{"unit_changeable"} = $form->{orphaned};
233 $main::lxdebug->leave_sub();
236 sub get_pricegroups {
237 $main::lxdebug->enter_sub();
239 my ($self, $myconfig, $form) = @_;
241 my $dbh = $form->dbconnect($myconfig);
244 my $query = qq|SELECT id, pricegroup FROM pricegroup|;
245 my $pricegroups = selectall_hashref_query($form, $dbh, $query);
248 foreach my $pg (@{ $pricegroups }) {
249 $form->{"klass_$i"} = "$pg->{id}";
250 $form->{"price_$i"} = $form->format_amount($myconfig, $form->{"price_$i"}, -2);
251 $form->{"pricegroup_id_$i"} = "$pg->{id}";
252 $form->{"pricegroup_$i"} = "$pg->{pricegroup}";
257 $form->{price_rows} = $i - 1;
261 $main::lxdebug->leave_sub();
266 sub retrieve_buchungsgruppen {
267 $main::lxdebug->enter_sub();
269 my ($self, $myconfig, $form) = @_;
273 my $dbh = $form->dbconnect($myconfig);
275 # get buchungsgruppen
276 $query = qq|SELECT id, description FROM buchungsgruppen ORDER BY sortkey|;
277 $form->{BUCHUNGSGRUPPEN} = selectall_hashref_query($form, $dbh, $query);
279 $main::lxdebug->leave_sub();
283 $main::lxdebug->enter_sub();
285 my ($self, $myconfig, $form) = @_;
287 # connect to database, turn off AutoCommit
288 my $dbh = $form->get_standard_dbh;
291 # make up a unique handle and store in partnumber field
292 # then retrieve the record based on the unique handle to get the id
293 # replace the partnumber field with the actual variable
294 # add records for makemodel
296 # if there is a $form->{id} then replace the old entry
297 # delete all makemodel entries and add the new ones
299 # undo amount formatting
300 map { $form->{$_} = $form->parse_amount($myconfig, $form->{$_}) }
301 qw(rop weight listprice sellprice gv lastcost);
303 my $makemodel = (($form->{make_1}) || ($form->{model_1})) ? 1 : 0;
305 $form->{assembly} = ($form->{item} eq 'assembly') ? 1 : 0;
309 my $priceupdate = ', priceupdate = current_date';
312 my $trans_number = SL::TransNumber->new(type => $form->{item}, dbh => $dbh, number => $form->{partnumber}, id => $form->{id});
313 if (!$trans_number->is_unique) {
314 $::lxdebug->leave_sub;
319 $query = qq|SELECT sellprice, weight FROM parts WHERE id = ?|;
320 my ($sellprice, $weight) = selectrow_query($form, $dbh, $query, conv_i($form->{id}));
322 # if item is part of an assembly adjust all assemblies
323 $query = qq|SELECT id, qty FROM assembly WHERE parts_id = ?|;
324 $sth = prepare_execute_query($form, $dbh, $query, conv_i($form->{id}));
325 while (my ($id, $qty) = $sth->fetchrow_array) {
326 &update_assembly($dbh, $form, $id, $qty, $sellprice * 1, $weight * 1);
330 # delete makemodel records
331 do_query($form, $dbh, qq|DELETE FROM makemodel WHERE parts_id = ?|, conv_i($form->{id}));
333 if ($form->{item} eq 'assembly') {
334 # delete assembly records
335 do_query($form, $dbh, qq|DELETE FROM assembly WHERE id = ?|, conv_i($form->{id}));
339 do_query($form, $dbh, qq|DELETE FROM partstax WHERE parts_id = ?|, conv_i($form->{id}));
341 # delete translations
342 do_query($form, $dbh, qq|DELETE FROM translation WHERE parts_id = ?|, conv_i($form->{id}));
344 # Check whether or not the prices have changed. If they haven't
345 # then 'priceupdate' should not be updated.
346 my $previous_values = selectfirst_hashref_query($form, $dbh, qq|SELECT * FROM parts WHERE id = ?|, conv_i($form->{id})) || {};
347 $priceupdate = '' if (all { $previous_values->{$_} == $form->{$_} } qw(sellprice lastcost listprice));
350 my $trans_number = SL::TransNumber->new(type => $form->{item}, dbh => $dbh, number => $form->{partnumber}, save => 1);
352 if ($form->{partnumber} && !$trans_number->is_unique) {
353 $::lxdebug->leave_sub;
357 $form->{partnumber} ||= $trans_number->create_unique;
359 ($form->{id}) = selectrow_query($form, $dbh, qq|SELECT nextval('id')|);
360 do_query($form, $dbh, qq|INSERT INTO parts (id, partnumber, unit) VALUES (?, ?, ?)|, $form->{id}, $form->{partnumber}, $form->{unit});
362 $form->{orphaned} = 1;
364 my $partsgroup_id = 0;
366 if ($form->{partsgroup}) {
367 (my $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,
418 not_discountable = ?,
424 @values = ($form->{partnumber},
425 $form->{description},
426 $makemodel ? 't' : 'f',
427 $form->{assembly} ? 't' : 'f',
437 conv_i($form->{buchungsgruppen_id}),
438 conv_i($form->{payment_id}),
439 conv_i($form->{buchungsgruppen_id}),
440 $form->{obsolete} ? 't' : 'f',
443 $form->{shop} ? 't' : 'f',
447 $form->{has_sernumber} ? 't' : 'f',
448 $form->{not_discountable} ? 't' : 'f',
450 conv_i($partsgroup_id),
451 conv_i($form->{price_factor_id}),
454 do_query($form, $dbh, $query, @values);
456 # delete translation records
457 do_query($form, $dbh, qq|DELETE FROM translation WHERE parts_id = ?|, conv_i($form->{id}));
459 if ($form->{language_values} ne "") {
460 foreach my $item (split(/---\+\+\+---/, $form->{language_values})) {
461 my ($language_id, $translation, $longdescription) = split(/--\+\+--/, $item);
462 if ($translation ne "") {
463 $query = qq|INSERT into translation (parts_id, language_id, translation, longdescription)
464 VALUES ( ?, ?, ?, ? )|;
465 @values = (conv_i($form->{id}), conv_i($language_id), $translation, $longdescription);
466 do_query($form, $dbh, $query, @values);
471 # delete price records
472 do_query($form, $dbh, qq|DELETE FROM prices WHERE parts_id = ?|, conv_i($form->{id}));
474 $query = qq|INSERT INTO prices (parts_id, pricegroup_id, price) VALUES(?, ?, ?)|;
475 $sth = prepare_query($form, $dbh, $query);
477 # insert price records only if different to sellprice
478 for my $i (1 .. $form->{price_rows}) {
479 my $price = $form->parse_amount($myconfig, $form->{"price_$i"});
480 next unless $price && ($price != $form->{sellprice});
482 @values = (conv_i($form->{id}), conv_i($form->{"pricegroup_id_$i"}), $price);
483 do_statement($form, $sth, $query, @values);
488 # insert makemodel records
491 for my $i (1 .. $form->{makemodel_rows}) {
492 if (($form->{"make_$i"}) || ($form->{"model_$i"})) {
494 $value = $form->parse_amount($myconfig, $form->{"lastcost_$i"});
495 if ($value == $form->parse_amount($myconfig, $form->{"old_lastcost_$i"}))
497 if ($form->{"lastupdate_$i"} eq "") {
498 $lastupdate = 'now()';
500 $lastupdate = $dbh->quote($form->{"lastupdate_$i"});
503 $lastupdate = 'now()';
505 $query = qq|INSERT INTO makemodel (parts_id, make, model, lastcost, lastupdate, sortorder) | .
506 qq|VALUES (?, ?, ?, ?, ?, ?)|;
507 @values = (conv_i($form->{id}), conv_i($form->{"make_$i"}), $form->{"model_$i"}, $value, $lastupdate, conv_i($form->{"sortorder_$i"}) );
509 do_query($form, $dbh, $query, @values);
514 foreach my $item (split(/ /, $form->{taxaccounts})) {
515 if ($form->{"IC_tax_$item"}) {
517 qq|INSERT INTO partstax (parts_id, chart_id)
518 VALUES (?, (SELECT id FROM chart WHERE accno = ?))|;
519 @values = (conv_i($form->{id}), $item);
520 do_query($form, $dbh, $query, @values);
524 # add assembly records
525 if ($form->{item} eq 'assembly') {
527 for my $i (1 .. $form->{assembly_rows}) {
528 $form->{"qty_$i"} = $form->parse_amount($myconfig, $form->{"qty_$i"});
530 if ($form->{"qty_$i"} != 0) {
531 $form->{"bom_$i"} *= 1;
532 $query = qq|INSERT INTO assembly (id, parts_id, qty, bom) | .
533 qq|VALUES (?, ?, ?, ?)|;
534 @values = (conv_i($form->{id}), conv_i($form->{"id_$i"}), conv_i($form->{"qty_$i"}), $form->{"bom_$i"} ? 't' : 'f');
535 do_query($form, $dbh, $query, @values);
542 my $shippingdate = "$a[5]-$a[4]-$a[3]";
544 $form->get_employee($dbh);
548 #set expense_accno=inventory_accno if they are different => bilanz
550 ($form->{expense_accno} != $form->{inventory_accno})
551 ? $form->{inventory_accno}
552 : $form->{expense_accno};
554 # get tax rates and description
556 ($form->{vc} eq "customer") ? $form->{income_accno} : $vendor_accno;
558 qq|SELECT c.accno, c.description, t.rate, t.taxnumber
560 WHERE (c.id = t.chart_id) AND (t.taxkey IN (SELECT taxkey_id FROM chart where accno = ?))
562 my $stw = prepare_execute_query($form, $dbh, $query, $accno_id);
564 $form->{taxaccount} = "";
565 while (my $ptr = $stw->fetchrow_hashref("NAME_lc")) {
566 $form->{taxaccount} .= "$ptr->{accno} ";
567 if (!($form->{taxaccount2} =~ /\Q$ptr->{accno}\E/)) {
568 $form->{"$ptr->{accno}_rate"} = $ptr->{rate};
569 $form->{"$ptr->{accno}_description"} = $ptr->{description};
570 $form->{"$ptr->{accno}_taxnumber"} = $ptr->{taxnumber};
571 $form->{taxaccount2} .= " $ptr->{accno} ";
575 CVar->save_custom_variables(dbh => $dbh,
577 trans_id => $form->{id},
582 my $rc = $dbh->commit;
584 $main::lxdebug->leave_sub();
589 sub update_assembly {
590 $main::lxdebug->enter_sub();
592 my ($dbh, $form, $id, $qty, $sellprice, $weight) = @_;
594 my $query = qq|SELECT id, qty FROM assembly WHERE parts_id = ?|;
595 my $sth = prepare_execute_query($form, $dbh, $query, conv_i($id));
597 while (my ($pid, $aqty) = $sth->fetchrow_array) {
598 &update_assembly($dbh, $form, $pid, $aqty * $qty, $sellprice, $weight);
603 qq|UPDATE parts SET sellprice = sellprice + ?, weight = weight + ?
605 my @values = ($qty * ($form->{sellprice} - $sellprice),
606 $qty * ($form->{weight} - $weight), conv_i($id));
607 do_query($form, $dbh, $query, @values);
609 $main::lxdebug->leave_sub();
612 sub retrieve_assemblies {
613 $main::lxdebug->enter_sub();
615 my ($self, $myconfig, $form) = @_;
617 # connect to database
618 my $dbh = $form->dbconnect($myconfig);
620 my $where = qq|NOT p.obsolete|;
623 if ($form->{partnumber}) {
624 $where .= qq| AND (p.partnumber ILIKE ?)|;
625 push(@values, '%' . $form->{partnumber} . '%');
628 if ($form->{description}) {
629 $where .= qq| AND (p.description ILIKE ?)|;
630 push(@values, '%' . $form->{description} . '%');
633 # retrieve assembly items
635 qq|SELECT p.id, p.partnumber, p.description,
636 p.bin, p.onhand, p.rop,
637 (SELECT sum(p2.inventory_accno_id)
638 FROM parts p2, assembly a
639 WHERE (p2.id = a.parts_id) AND (a.id = p.id)) AS inventory
641 WHERE NOT p.obsolete AND p.assembly $where|;
643 $form->{assembly_items} = selectall_hashref_query($form, $dbh, $query, @values);
647 $main::lxdebug->leave_sub();
651 $main::lxdebug->enter_sub();
653 my ($self, $myconfig, $form) = @_;
654 my @values = (conv_i($form->{id}));
655 # connect to database, turn off AutoCommit
656 my $dbh = $form->dbconnect_noauto($myconfig);
658 my %columns = ( "assembly" => "id", "parts" => "id" );
660 for my $table (qw(prices partstax makemodel inventory assembly translation parts)) {
661 my $column = defined($columns{$table}) ? $columns{$table} : "parts_id";
662 do_query($form, $dbh, qq|DELETE FROM $table WHERE $column = ?|, @values);
666 my $rc = $dbh->commit;
669 $main::lxdebug->leave_sub();
675 $main::lxdebug->enter_sub();
677 my ($self, $myconfig, $form) = @_;
679 my $i = $form->{assembly_rows};
681 my $where = qq|1 = 1|;
684 my %columns = ("partnumber" => "p", "description" => "p", "partsgroup" => "pg");
686 while (my ($column, $table) = each(%columns)) {
687 next unless ($form->{"${column}_$i"});
688 $where .= qq| AND ${table}.${column} ILIKE ?|;
689 push(@values, '%' . $form->{"${column}_$i"} . '%');
693 $where .= qq| AND NOT (p.id = ?)|;
694 push(@values, conv_i($form->{id}));
697 # Search for part ID overrides all other criteria.
698 if ($form->{"id_${i}"}) {
699 $where = qq|p.id = ?|;
700 @values = ($form->{"id_${i}"});
703 if ($form->{partnumber}) {
704 $where .= qq| ORDER BY p.partnumber|;
706 $where .= qq| ORDER BY p.description|;
709 # connect to database
710 my $dbh = $form->dbconnect($myconfig);
713 qq|SELECT p.id, p.partnumber, p.description, p.sellprice,
714 p.weight, p.onhand, p.unit, pg.partsgroup, p.lastcost,
715 p.price_factor_id, pfac.factor AS price_factor
717 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
718 LEFT JOIN price_factors pfac ON pfac.id = p.price_factor_id
720 $form->{item_list} = selectall_hashref_query($form, $dbh, $query, @values);
724 $main::lxdebug->leave_sub();
729 # Warning, deep magic ahead.
730 # This function gets all parts from the database according to the filters specified
733 # sort revers - sorting field + direction
736 # simple filter strings (every one of those also has a column flag prefixed with 'l_' associated):
737 # partnumber ean description partsgroup microfiche drawing
740 # 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
743 # itemstatus = active | onhand | short | obsolete | orphaned
744 # searchitems = part | assembly | service
747 # make model - makemodel
748 # serialnumber transdatefrom transdateto - invoice/orderitems
751 # bought sold onorder ordered rfq quoted - aggreg joins with invoices/orders
752 # l_linetotal l_subtotal - aggreg joins to display totals (complicated) - NOT IMPLEMENTED here, implementation at frontend
753 # l_soldtotal - aggreg join to display total of sold quantity
754 # onhand - as above, but masking the simple itemstatus results (doh!)
755 # short - NOT IMPLEMENTED as form filter, only as itemstatus option
756 # l_serialnumber - belonges to serialnumber filter
757 # l_deliverydate - displays deliverydate is sold etc. flags are active
758 # l_soldtotal - aggreg join to display total of sold quantity, works as long as there's no bullshit in soldtotal
761 # onhand - as above, but masking the simple itemstatus results (doh!)
763 # search by overrides of description
765 # disabled sanity checks and changes:
766 # - searchitems = assembly will no longer disable bought
767 # - searchitems = service will no longer disable make and model, although services don't have make/model, it doesn't break the query
768 # - itemstatus = orphaned will no longer disable onhand short bought sold onorder ordered rfq quoted transdate[from|to]
769 # - itemstatus = obsolete will no longer disable onhand, short
770 # - allow sorting by ean
771 # - serialnumber filter also works if l_serialnumber isn't ticked
772 # - sorting will now change sorting if the requested sorting column isn't checked and doesn't get checked as a side effect
775 $main::lxdebug->enter_sub();
777 my ($self, $myconfig, $form) = @_;
778 my $dbh = $form->get_standard_dbh($myconfig);
780 $form->{parts} = +{ };
781 $form->{soldtotal} = undef if $form->{l_soldtotal}; # security fix. top100 insists on putting strings in there...
783 my @simple_filters = qw(partnumber ean description partsgroup microfiche drawing onhand);
784 my @project_filters = qw(projectnumber projectdescription);
785 my @makemodel_filters = qw(make model);
786 my @invoice_oi_filters = qw(serialnumber soldtotal);
787 my @apoe_filters = qw(transdate);
788 my @like_filters = (@simple_filters, @invoice_oi_filters);
789 my @all_columns = (@simple_filters, @makemodel_filters, @apoe_filters, @project_filters, qw(serialnumber));
790 my @simple_l_switches = (@all_columns, qw(notes listprice sellprice lastcost priceupdate weight unit bin rop image));
791 my @oe_flags = qw(bought sold onorder ordered rfq quoted);
792 my @qsooqr_flags = qw(invnumber ordnumber quonumber trans_id name module qty);
793 my @deliverydate_flags = qw(deliverydate);
794 # my @other_flags = qw(onhand); # ToDO: implement these
795 # my @inactive_flags = qw(l_subtotal short l_linetotal);
797 my @select_tokens = qw(id factor);
798 my @where_tokens = qw(1=1);
799 my @group_tokens = ();
801 my %joins_needed = ();
804 partsgroup => 'LEFT JOIN partsgroup pg ON (pg.id = p.partsgroup_id)',
805 makemodel => 'LEFT JOIN makemodel mm ON (mm.parts_id = p.id)',
806 pfac => 'LEFT JOIN price_factors pfac ON (pfac.id = p.price_factor_id)',
809 SELECT parts_id, description, serialnumber, trans_id, unit, sellprice, qty, assemblyitem, deliverydate, 'invoice' AS ioi, project_id, id FROM invoice UNION
810 SELECT parts_id, description, serialnumber, trans_id, unit, sellprice, qty, FALSE AS assemblyitem, NULL AS deliverydate, 'orderitems' AS ioi, project_id, id FROM orderitems
811 ) AS ioi ON ioi.parts_id = p.id|,
814 SELECT id, transdate, 'ir' AS module, ordnumber, quonumber, invnumber, FALSE AS quotation, NULL AS customer_id, vendor_id, NULL AS deliverydate, globalproject_id, 'invoice' AS ioi FROM ap UNION
815 SELECT id, transdate, 'is' AS module, ordnumber, quonumber, invnumber, FALSE AS quotation, customer_id, NULL AS vendor_id, deliverydate, globalproject_id, 'invoice' AS ioi FROM ar UNION
816 SELECT id, transdate, 'oe' AS module, ordnumber, quonumber, NULL AS invnumber, quotation, customer_id, vendor_id, reqdate AS deliverydate, globalproject_id, 'orderitems' AS ioi FROM oe
817 ) AS apoe ON ((ioi.trans_id = apoe.id) AND (ioi.ioi = apoe.ioi))|,
820 SELECT id, name, 'customer' AS cv FROM customer UNION
821 SELECT id, name, 'vendor' AS cv FROM vendor
822 ) AS cv ON cv.id = apoe.customer_id OR cv.id = apoe.vendor_id|,
823 mv => 'LEFT JOIN vendor AS mv ON mv.id = mm.make',
824 project => 'LEFT JOIN project AS pj ON pj.id = COALESCE(ioi.project_id, apoe.globalproject_id)',
826 my @join_order = qw(partsgroup makemodel mv invoice_oi apoe cv pfac project);
829 deliverydate => 'apoe.', serialnumber => 'ioi.',
830 transdate => 'apoe.', trans_id => 'ioi.',
831 module => 'apoe.', name => 'cv.',
832 ordnumber => 'apoe.', make => 'mm.',
833 quonumber => 'apoe.', model => 'mm.',
834 invnumber => 'apoe.', partsgroup => 'pg.',
835 lastcost => 'p.', , soldtotal => ' ',
836 factor => 'pfac.', projectnumber => 'pj.',
837 'SUM(ioi.qty)' => ' ', projectdescription => 'pj.',
840 serialnumber => 'ioi.',
841 quotation => 'apoe.',
847 # if the join condition in these blocks are met, the column
848 # of the scecified table will gently override (coalesce actually) the original value
849 # use it to conditionally coalesce values from subtables
850 my @column_override = (
851 # column name, prefix, joins_needed, nick name (in case column is named like another)
852 [ 'description', 'ioi.', 'invoice_oi' ],
853 [ 'deliverydate', 'ioi.', 'invoice_oi' ],
854 [ 'transdate', 'apoe.', 'apoe' ],
855 [ 'unit', 'ioi.', 'invoice_oi' ],
856 [ 'sellprice', 'ioi.', 'invoice_oi' ],
859 # careful with renames. these are HARD, and any filters done on the original column will break
860 my %renamed_columns = (
861 'factor' => 'price_factor',
862 'SUM(ioi.qty)' => 'soldtotal',
863 'ioi.id' => 'ioi_id',
865 'projectdescription' => 'projectdescription',
869 projectdescription => 'description',
872 if (($form->{searchitems} eq 'assembly') && $form->{l_lastcost}) {
873 @simple_l_switches = grep { $_ ne 'lastcost' } @simple_l_switches;
876 my $make_token_builder = sub {
877 my $joins_needed = shift;
879 my ($nick, $alias) = @_;
880 my ($col) = $real_column{$nick} || $nick;
881 my @coalesce_tokens =
882 map { ($_->[1] || 'p.') . $_->[0] }
883 grep { !$_->[2] || $joins_needed->{$_->[2]} }
884 grep { ($_->[3] || $_->[0]) eq $nick }
885 @column_override, [ $col, $table_prefix{$nick}, undef , $nick ];
887 my $coalesce = scalar @coalesce_tokens > 1;
889 ? sprintf 'COALESCE(%s)', join ', ', @coalesce_tokens
890 : shift @coalesce_tokens)
891 . ($alias && ($coalesce || $renamed_columns{$nick})
892 ? " AS " . ($renamed_columns{$nick} || $nick)
897 #===== switches and simple filters ========#
899 # special case transdate
900 if (grep { $form->{$_} } qw(transdatefrom transdateto)) {
901 $form->{"l_transdate"} = 1;
902 push @select_tokens, 'transdate';
903 for (qw(transdatefrom transdateto)) {
904 next unless $form->{$_};
905 push @where_tokens, sprintf "transdate %s ?", /from$/ ? '>=' : '<=';
906 push @bind_vars, $form->{$_};
910 if ($form->{"partsgroup_id"}) {
911 $form->{"l_partsgroup"} = '1'; # show the column
912 push @where_tokens, "pg.id = ?";
913 push @bind_vars, $form->{"partsgroup_id"};
916 foreach (@like_filters) {
917 next unless $form->{$_};
918 $form->{"l_$_"} = '1'; # show the column
919 push @where_tokens, "$table_prefix{$_}$_ ILIKE ?";
920 push @bind_vars, "%$form->{$_}%";
923 foreach (@simple_l_switches) {
924 next unless $form->{"l_$_"};
925 push @select_tokens, $_;
928 for ($form->{searchitems}) {
929 push @where_tokens, 'p.inventory_accno_id > 0' if /part/;
930 push @where_tokens, 'p.inventory_accno_id IS NULL' if /service/;
931 push @where_tokens, 'NOT p.assembly' if /service/;
932 push @where_tokens, ' p.assembly' if /assembly/;
935 for ($form->{itemstatus}) {
936 push @where_tokens, 'p.id NOT IN
937 (SELECT DISTINCT parts_id FROM invoice UNION
938 SELECT DISTINCT parts_id FROM assembly UNION
939 SELECT DISTINCT parts_id FROM orderitems)' if /orphaned/;
940 push @where_tokens, 'p.onhand = 0' if /orphaned/;
941 push @where_tokens, 'NOT p.obsolete' if /active/;
942 push @where_tokens, ' p.obsolete', if /obsolete/;
943 push @where_tokens, 'p.onhand > 0', if /onhand/;
944 push @where_tokens, 'p.onhand < p.rop', if /short/;
947 my $q_assembly_lastcost =
948 qq|(SELECT SUM(a_lc.qty * p_lc.lastcost / COALESCE(pfac_lc.factor, 1))
950 LEFT JOIN parts p_lc ON (a_lc.parts_id = p_lc.id)
951 LEFT JOIN price_factors pfac_lc ON (p_lc.price_factor_id = pfac_lc.id)
952 WHERE (a_lc.id = p.id)) AS lastcost|;
953 $table_prefix{$q_assembly_lastcost} = ' ';
955 # special case makemodel search
956 # all_parts is based upon the assumption that every parameter is named like the column it represents
957 # unfortunately make would have to match vendor.name which is already taken for vendor.name in bsooqr mode.
958 # fortunately makemodel doesn't need to be displayed later, so adding a special clause to where_token is sufficient.
960 push @where_tokens, 'mv.name ILIKE ?';
961 push @bind_vars, "%$form->{make}%";
963 if ($form->{model}) {
964 push @where_tokens, 'mm.model ILIKE ?';
965 push @bind_vars, "%$form->{model}%";
968 # special case: sorting by partnumber
969 # since partnumbers are expected to be prefixed integers, a special sorting is implemented sorting first lexically by prefix and then by suffix.
970 # and yes, that expression is designed to hold that array of regexes only once, so the map is kinda messy, sorry about that.
971 # ToDO: implement proper functional sorting
972 # Nette Idee von Sven, gibt aber Probleme wenn die Artikelnummern groesser als 32bit sind. Korrekt waere es, dass Sort-Natural-Modul zu nehmen
973 # Ich lass das mal hier drin, damit die Idee erhalten bleibt jb 28.5.2009 bug 1018
974 #$form->{sort} = join ', ', map { push @select_tokens, $_; ($table_prefix{$_} = "substring(partnumber,'[") . $_ } qw|^[:digit:]]+') [:digit:]]+')::INTEGER|
975 # if $form->{sort} eq 'partnumber';
977 #my $order_clause = " ORDER BY $form->{sort} $sort_order";
980 $limit_clause = " LIMIT 100" if $form->{top100};
981 $limit_clause = " LIMIT " . $form->{limit} * 1 if $form->{limit} * 1;
983 #=== joins and complicated filters ========#
985 my $bsooqr = any { $form->{$_} } @oe_flags;
986 my @bsooqr_tokens = ();
988 push @select_tokens, @qsooqr_flags, 'quotation', 'cv', 'ioi.id', 'ioi.ioi' if $bsooqr;
989 push @select_tokens, @deliverydate_flags if $bsooqr && $form->{l_deliverydate};
990 push @select_tokens, $q_assembly_lastcost if ($form->{searchitems} eq 'assembly') && $form->{l_lastcost};
991 push @bsooqr_tokens, q|module = 'ir' AND NOT ioi.assemblyitem| if $form->{bought};
992 push @bsooqr_tokens, q|module = 'is' AND NOT ioi.assemblyitem| if $form->{sold};
993 push @bsooqr_tokens, q|module = 'oe' AND NOT quotation AND cv = 'customer'| if $form->{ordered};
994 push @bsooqr_tokens, q|module = 'oe' AND NOT quotation AND cv = 'vendor'| if $form->{onorder};
995 push @bsooqr_tokens, q|module = 'oe' AND quotation AND cv = 'customer'| if $form->{quoted};
996 push @bsooqr_tokens, q|module = 'oe' AND quotation AND cv = 'vendor'| if $form->{rfq};
997 push @where_tokens, join ' OR ', map { "($_)" } @bsooqr_tokens if $bsooqr;
999 $joins_needed{partsgroup} = 1;
1000 $joins_needed{pfac} = 1;
1001 $joins_needed{project} = 1 if grep { $form->{$_} || $form->{"l_$_"} } @project_filters;
1002 $joins_needed{makemodel} = 1 if grep { $form->{$_} || $form->{"l_$_"} } @makemodel_filters;
1003 $joins_needed{mv} = 1 if $joins_needed{makemodel};
1004 $joins_needed{cv} = 1 if $bsooqr;
1005 $joins_needed{apoe} = 1 if $joins_needed{project} || $joins_needed{cv} || grep { $form->{$_} || $form->{"l_$_"} } @apoe_filters;
1006 $joins_needed{invoice_oi} = 1 if $joins_needed{project} || $joins_needed{apoe} || grep { $form->{$_} || $form->{"l_$_"} } @invoice_oi_filters;
1008 # special case for description search.
1009 # up in the simple filter section the description filter got interpreted as something like: WHERE description ILIKE '%$form->{description}%'
1010 # now we'd like to search also for the masked description entered in orderitems and invoice, so...
1011 # find the old entries in of @where_tokens and @bind_vars, and adjust them
1012 if ($joins_needed{invoice_oi}) {
1013 for (my ($wi, $bi) = (0)x2; $wi <= $#where_tokens; $bi++ if $where_tokens[$wi++] =~ /\?/) {
1014 next unless $where_tokens[$wi] =~ /\bdescription ILIKE/;
1015 splice @where_tokens, $wi, 1, 'p.description ILIKE ? OR ioi.description ILIKE ?';
1016 splice @bind_vars, $bi, 0, $bind_vars[$bi];
1021 # now the master trick: soldtotal.
1022 if ($form->{l_soldtotal}) {
1023 push @where_tokens, 'NOT ioi.qty = 0';
1024 push @group_tokens, @select_tokens;
1025 map { s/.*\sAS\s+//si } @group_tokens;
1026 push @select_tokens, 'SUM(ioi.qty)';
1029 #============= build query ================#
1031 my $token_builder = $make_token_builder->(\%joins_needed);
1033 my @sort_cols = (@simple_filters, qw(id bin priceupdate onhand invnumber ordnumber quonumber name serialnumber soldtotal deliverydate));
1034 $form->{sort} = 'id' unless grep { $form->{"l_$_"} } grep { $form->{sort} eq $_ } @sort_cols; # sort by id if unknown or invisible column
1035 my $sort_order = ($form->{revers} ? ' DESC' : ' ASC');
1036 my $order_clause = " ORDER BY " . $token_builder->($form->{sort}) . ($form->{revers} ? ' DESC' : ' ASC');
1038 my $select_clause = join ', ', map { $token_builder->($_, 1) } @select_tokens;
1039 my $join_clause = join ' ', @joins{ grep $joins_needed{$_}, @join_order };
1040 my $where_clause = join ' AND ', map { "($_)" } @where_tokens;
1041 my $group_clause = @group_tokens ? ' GROUP BY ' . join ', ', map { $token_builder->($_) } @group_tokens : '';
1043 my %oe_flag_to_cvar = (
1044 bought => 'invoice',
1046 onorder => 'orderitems',
1047 ordered => 'orderitems',
1048 rfq => 'orderitems',
1049 quoted => 'orderitems',
1052 my ($cvar_where, @cvar_values) = CVar->build_filter_query(
1054 trans_id_field => $bsooqr ? 'ioi.id': 'p.id',
1056 sub_module => $bsooqr ? [ uniq grep { $oe_flag_to_cvar{$form->{$_}} } @oe_flags ] : undef,
1060 $where_clause .= qq| AND ($cvar_where)|;
1061 push @bind_vars, @cvar_values;
1064 my $query = <<" SQL";
1065 SELECT DISTINCT $select_clause
1074 $form->{parts} = selectall_hashref_query($form, $dbh, $query, @bind_vars);
1076 map { $_->{onhand} *= 1 } @{ $form->{parts} };
1078 # fix qty sign in ap. those are saved negative
1079 if ($bsooqr && $form->{bought}) {
1080 for my $row (@{ $form->{parts} }) {
1081 $row->{qty} *= -1 if $row->{module} eq 'ir';
1085 # post processing for assembly parts lists (bom)
1086 # for each part get the assembly parts and add them into the partlist.
1088 if ($form->{searchitems} eq 'assembly' && $form->{bom}) {
1090 qq|SELECT p.id, p.partnumber, p.description, a.qty AS onhand,
1091 p.unit, p.bin, p.notes,
1092 p.sellprice, p.listprice, p.lastcost,
1093 p.rop, p.weight, p.priceupdate,
1094 p.image, p.drawing, p.microfiche,
1097 INNER JOIN assembly a ON (p.id = a.parts_id)
1100 my $sth = prepare_query($form, $dbh, $query);
1102 foreach my $item (@{ $form->{parts} }) {
1103 push(@assemblies, $item);
1104 do_statement($form, $sth, $query, conv_i($item->{id}));
1106 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
1107 $ref->{assemblyitem} = 1;
1108 map { $ref->{$_} /= $ref->{factor} || 1 } qw(sellprice listprice lastcost);
1109 push(@assemblies, $ref);
1114 # copy assemblies to $form->{parts}
1115 $form->{parts} = \@assemblies;
1118 if ($form->{l_pricegroups} ) {
1120 SELECT parts_id, price, pricegroup_id
1125 my $sth = prepare_query($form, $dbh, $query);
1127 foreach my $part (@{ $form->{parts} }) {
1128 do_statement($form, $sth, $query, conv_i($part->{id}));
1130 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
1131 $part->{"pricegroup_$ref->{pricegroup_id}"} = $ref->{price};
1138 $main::lxdebug->leave_sub();
1140 return wantarray ? @{ $form->{parts} } : $form->{parts};
1143 sub _create_filter_for_priceupdate {
1144 $main::lxdebug->enter_sub();
1147 my $myconfig = \%main::myconfig;
1148 my $form = $main::form;
1151 my $where = '1 = 1';
1153 foreach my $item (qw(partnumber drawing microfiche make model pg.partsgroup)) {
1155 $column =~ s/.*\.//;
1156 next unless ($form->{$column});
1158 $where .= qq| AND $item ILIKE ?|;
1159 push(@where_values, '%' . $form->{$column} . '%');
1162 foreach my $item (qw(description serialnumber)) {
1163 next unless ($form->{$item});
1165 $where .= qq| AND (${item} ILIKE ?)|;
1166 push(@where_values, '%' . $form->{$item} . '%');
1170 # items which were never bought, sold or on an order
1171 if ($form->{itemstatus} eq 'orphaned') {
1173 qq| AND (p.onhand = 0)
1176 SELECT DISTINCT parts_id FROM invoice
1178 SELECT DISTINCT parts_id FROM assembly
1180 SELECT DISTINCT parts_id FROM orderitems
1183 } elsif ($form->{itemstatus} eq 'active') {
1184 $where .= qq| AND p.obsolete = '0'|;
1186 } elsif ($form->{itemstatus} eq 'obsolete') {
1187 $where .= qq| AND p.obsolete = '1'|;
1189 } elsif ($form->{itemstatus} eq 'onhand') {
1190 $where .= qq| AND p.onhand > 0|;
1192 } elsif ($form->{itemstatus} eq 'short') {
1193 $where .= qq| AND p.onhand < p.rop|;
1197 foreach my $column (qw(make model)) {
1198 next unless ($form->{$column});
1199 $where .= qq| AND p.id IN (SELECT DISTINCT parts_id FROM makemodel WHERE $column ILIKE ?|;
1200 push(@where_values, '%' . $form->{$column} . '%');
1203 $main::lxdebug->leave_sub();
1205 return ($where, @where_values);
1208 sub get_num_matches_for_priceupdate {
1209 $main::lxdebug->enter_sub();
1213 my $myconfig = \%main::myconfig;
1214 my $form = $main::form;
1216 my $dbh = $form->get_standard_dbh($myconfig);
1218 my ($where, @where_values) = $self->_create_filter_for_priceupdate();
1220 my $num_updated = 0;
1223 for my $column (qw(sellprice listprice)) {
1224 next if ($form->{$column} eq "");
1232 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
1234 my ($result) = selectfirst_array_query($form, $dbh, $query, @where_values);
1235 $num_updated += $result if (0 <= $result);
1244 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
1245 WHERE $where) AND (pricegroup_id = ?)|;
1246 my $sth = prepare_query($form, $dbh, $query);
1248 for my $i (1 .. $form->{price_rows}) {
1249 next if ($form->{"price_$i"} eq "");
1251 my ($result) = do_statement($form, $sth, $query, @where_values, conv_i($form->{"pricegroup_id_$i"}));
1252 $num_updated += $result if (0 <= $result);
1256 $main::lxdebug->leave_sub();
1258 return $num_updated;
1262 $main::lxdebug->enter_sub();
1264 my ($self, $myconfig, $form) = @_;
1266 my ($where, @where_values) = $self->_create_filter_for_priceupdate();
1267 my $num_updated = 0;
1269 # connect to database
1270 my $dbh = $form->dbconnect_noauto($myconfig);
1272 for my $column (qw(sellprice listprice)) {
1273 next if ($form->{$column} eq "");
1275 my $value = $form->parse_amount($myconfig, $form->{$column});
1278 if ($form->{"${column}_type"} eq "percent") {
1279 $value = ($value / 100) + 1;
1284 qq|UPDATE parts SET $column = $column $operator ?
1288 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
1290 my $result = do_query($form, $dbh, $query, $value, @where_values);
1291 $num_updated += $result if (0 <= $result);
1295 qq|UPDATE prices SET price = price + ?
1299 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
1300 WHERE $where) AND (pricegroup_id = ?)|;
1301 my $sth_add = prepare_query($form, $dbh, $q_add);
1304 qq|UPDATE prices SET price = price * ?
1308 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
1309 WHERE $where) AND (pricegroup_id = ?)|;
1310 my $sth_multiply = prepare_query($form, $dbh, $q_multiply);
1312 for my $i (1 .. $form->{price_rows}) {
1313 next if ($form->{"price_$i"} eq "");
1315 my $value = $form->parse_amount($myconfig, $form->{"price_$i"});
1318 if ($form->{"pricegroup_type_$i"} eq "percent") {
1319 $result = do_statement($form, $sth_multiply, $q_multiply, ($value / 100) + 1, @where_values, conv_i($form->{"pricegroup_id_$i"}));
1321 $result = do_statement($form, $sth_add, $q_add, $value, @where_values, conv_i($form->{"pricegroup_id_$i"}));
1324 $num_updated += $result if (0 <= $result);
1328 $sth_multiply->finish();
1330 my $rc= $dbh->commit;
1333 $main::lxdebug->leave_sub();
1335 return $num_updated;
1339 $main::lxdebug->enter_sub();
1341 my ($self, $module, $myconfig, $form) = @_;
1343 # connect to database
1344 my $dbh = $form->dbconnect($myconfig);
1346 my @values = ('%' . $module . '%');
1351 qq|SELECT c.accno, c.description, c.link, c.id,
1352 p.inventory_accno_id, p.income_accno_id, p.expense_accno_id
1353 FROM chart c, parts p
1354 WHERE (c.link LIKE ?) AND (p.id = ?)
1356 push(@values, conv_i($form->{id}));
1360 qq|SELECT c.accno, c.description, c.link, c.id,
1361 d.inventory_accno_id, d.income_accno_id, d.expense_accno_id
1362 FROM chart c, defaults d
1367 my $sth = prepare_execute_query($form, $dbh, $query, @values);
1368 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
1369 foreach my $key (split(/:/, $ref->{link})) {
1370 if ($key =~ /\Q$module\E/) {
1371 if ( ($ref->{id} eq $ref->{inventory_accno_id})
1372 || ($ref->{id} eq $ref->{income_accno_id})
1373 || ($ref->{id} eq $ref->{expense_accno_id})) {
1374 push @{ $form->{"${module}_links"}{$key} },
1375 { accno => $ref->{accno},
1376 description => $ref->{description},
1377 selected => "selected" };
1378 $form->{"${key}_default"} = "$ref->{accno}--$ref->{description}";
1380 push @{ $form->{"${module}_links"}{$key} },
1381 { accno => $ref->{accno},
1382 description => $ref->{description},
1390 # get buchungsgruppen
1391 $form->{BUCHUNGSGRUPPEN} = selectall_hashref_query($form, $dbh, qq|SELECT id, description FROM buchungsgruppen|);
1394 $form->{payment_terms} = selectall_hashref_query($form, $dbh, qq|SELECT id, description FROM payment_terms ORDER BY sortkey|);
1397 ($form->{priceupdate}) = selectrow_query($form, $dbh, qq|SELECT current_date|);
1401 $main::lxdebug->leave_sub();
1404 # get partnumber, description, unit, sellprice and soldtotal with choice through $sortorder for Top100
1406 $main::lxdebug->enter_sub();
1408 my ($self, $myconfig, $form, $sortorder) = @_;
1409 my $dbh = $form->dbconnect($myconfig);
1410 my $order = qq| p.partnumber|;
1411 my $where = qq|1 = 1|;
1414 if ($sortorder eq "all") {
1415 $where .= qq| AND (partnumber ILIKE ?) AND (description ILIKE ?)|;
1416 push(@values, '%' . $form->{partnumber} . '%', '%' . $form->{description} . '%');
1418 } elsif ($sortorder eq "partnumber") {
1419 $where .= qq| AND (partnumber ILIKE ?)|;
1420 push(@values, '%' . $form->{partnumber} . '%');
1422 } elsif ($sortorder eq "description") {
1423 $where .= qq| AND (description ILIKE ?)|;
1424 push(@values, '%' . $form->{description} . '%');
1425 $order = "description";
1430 qq|SELECT id, partnumber, description, unit, sellprice
1432 WHERE $where ORDER BY $order|;
1434 my $sth = prepare_execute_query($form, $dbh, $query, @values);
1437 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
1438 if (($ref->{partnumber} eq "*") && ($ref->{description} eq "")) {
1443 $form->{"id_$j"} = $ref->{id};
1444 $form->{"partnumber_$j"} = $ref->{partnumber};
1445 $form->{"description_$j"} = $ref->{description};
1446 $form->{"unit_$j"} = $ref->{unit};
1447 $form->{"sellprice_$j"} = $ref->{sellprice};
1448 $form->{"soldtotal_$j"} = get_soldtotal($dbh, $ref->{id});
1454 $main::lxdebug->leave_sub();
1459 # gets sum of sold part with part_id
1461 $main::lxdebug->enter_sub();
1463 my ($dbh, $id) = @_;
1465 my $query = qq|SELECT sum(qty) FROM invoice WHERE parts_id = ?|;
1466 my ($sum) = selectrow_query($main::form, $dbh, $query, conv_i($id));
1469 $main::lxdebug->leave_sub();
1472 } #end get_soldtotal
1474 sub retrieve_languages {
1475 $main::lxdebug->enter_sub();
1477 my ($self, $myconfig, $form) = @_;
1479 # connect to database
1480 my $dbh = $form->dbconnect($myconfig);
1486 if ($form->{language_values} ne "") {
1488 qq|SELECT l.id, l.description, tr.translation, tr.longdescription
1490 LEFT OUTER JOIN translation tr ON (tr.language_id = l.id) AND (tr.parts_id = ?)
1491 ORDER BY lower(l.description)|;
1492 @values = (conv_i($form->{id}));
1495 $query = qq|SELECT id, description
1497 ORDER BY lower(description)|;
1500 my $languages = selectall_hashref_query($form, $dbh, $query, @values);
1504 $main::lxdebug->leave_sub();
1509 sub follow_account_chain {
1510 $main::lxdebug->enter_sub(2);
1512 my ($self, $form, $dbh, $transdate, $accno_id, $accno) = @_;
1514 my @visited_accno_ids = ($accno_id);
1518 $form->{ACCOUNT_CHAIN_BY_ID} ||= {
1519 map { $_->{id} => $_ }
1520 selectall_hashref_query($form, $dbh, <<SQL, $transdate) };
1521 SELECT c.id, c.new_chart_id, date(?) >= c.valid_from AS is_valid, cnew.accno
1523 LEFT JOIN chart cnew ON c.new_chart_id = cnew.id
1524 WHERE NOT c.new_chart_id IS NULL AND (c.new_chart_id > 0)
1528 my $ref = $form->{ACCOUNT_CHAIN_BY_ID}->{$accno_id};
1529 last unless ($ref && $ref->{"is_valid"} &&
1530 !grep({ $_ == $ref->{"new_chart_id"} } @visited_accno_ids));
1531 $accno_id = $ref->{"new_chart_id"};
1532 $accno = $ref->{"accno"};
1533 push(@visited_accno_ids, $accno_id);
1536 $main::lxdebug->leave_sub(2);
1538 return ($accno_id, $accno);
1541 sub retrieve_accounts {
1542 $main::lxdebug->enter_sub;
1545 my $myconfig = shift;
1547 my $dbh = $form->get_standard_dbh;
1548 my %args = @_; # index => part_id
1550 $form->{taxzone_id} *= 1;
1552 return unless grep $_, values %args; # shortfuse if no part_id supplied
1554 # transdate madness.
1556 if ($form->{type} eq "invoice") {
1557 if (($form->{vc} eq "vendor") || !$form->{deliverydate}) {
1558 $transdate = $form->{invdate};
1560 $transdate = $form->{deliverydate};
1562 } elsif (($form->{type} eq "credit_note") and $form->{deliverydate}) {
1563 # if credit_note has a deliverydate, use this instead of invdate
1564 # useful for credit_notes of invoices from an old period with different tax
1565 # if there is no deliverydate then invdate is used, old default (see next elsif)
1566 $transdate = $form->{deliverydate};
1567 } elsif (($form->{type} eq "credit_note") || ($form->{script} eq 'ir.pl')) {
1568 $transdate = $form->{invdate};
1570 $transdate = $form->{transdate};
1573 if ($transdate eq "") {
1574 $transdate = DateTime->today_local->to_lxoffice;
1576 $transdate = $dbh->quote($transdate);
1579 my $inc_exp = $form->{"vc"} eq "customer" ? "income_accno_id" : "expense_accno_id";
1581 my @part_ids = grep { $_ } values %args;
1582 my $in = join ',', ('?') x @part_ids;
1584 my %accno_by_part = map { $_->{id} => $_ }
1585 selectall_hashref_query($form, $dbh, <<SQL, @part_ids);
1587 p.id, p.inventory_accno_id AS is_part,
1588 bg.inventory_accno_id,
1589 bg.income_accno_id_$form->{taxzone_id} AS income_accno_id,
1590 bg.expense_accno_id_$form->{taxzone_id} AS expense_accno_id,
1591 c1.accno AS inventory_accno,
1592 c2.accno AS income_accno,
1593 c3.accno AS expense_accno
1595 LEFT JOIN buchungsgruppen bg ON p.buchungsgruppen_id = bg.id
1596 LEFT JOIN chart c1 ON bg.inventory_accno_id = c1.id
1597 LEFT JOIN chart c2 ON bg.income_accno_id_$form->{taxzone_id} = c2.id
1598 LEFT JOIN chart c3 ON bg.expense_accno_id_$form->{taxzone_id} = c3.id
1602 my $sth_tax = prepare_query($::form, $dbh, <<SQL);
1603 SELECT c.accno, t.taxdescription AS description, t.rate, t.taxnumber
1605 LEFT JOIN chart c ON c.id = t.chart_id
1609 WHERE tk.chart_id = ? AND startdate <= ?
1610 ORDER BY startdate DESC LIMIT 1)
1613 while (my ($index => $part_id) = each %args) {
1614 my $ref = $accno_by_part{$part_id} or next;
1616 $ref->{"inventory_accno_id"} = undef unless $ref->{"is_part"};
1619 for my $type (qw(inventory income expense)) {
1620 next unless $ref->{"${type}_accno_id"};
1621 ($accounts{"${type}_accno_id"}, $accounts{"${type}_accno"}) =
1622 $self->follow_account_chain($form, $dbh, $transdate, $ref->{"${type}_accno_id"}, $ref->{"${type}_accno"});
1625 $form->{"${_}_accno_$index"} = $accounts{"${_}_accno"} for qw(inventory income expense);
1627 $sth_tax->execute($accounts{$inc_exp}, quote_db_date($transdate));
1628 $ref = $sth_tax->fetchrow_hashref or next;
1630 $form->{"taxaccounts_$index"} = $ref->{"accno"};
1631 $form->{"taxaccounts"} .= "$ref->{accno} "if $form->{"taxaccounts"} !~ /$ref->{accno}/;
1633 $form->{"$ref->{accno}_${_}"} = $ref->{$_} for qw(rate description taxnumber);
1638 $::lxdebug->leave_sub;
1641 sub get_basic_part_info {
1642 $main::lxdebug->enter_sub();
1647 Common::check_params(\%params, qw(id));
1649 my @ids = 'ARRAY' eq ref $params{id} ? @{ $params{id} } : ($params{id});
1652 $main::lxdebug->leave_sub();
1656 my $myconfig = \%main::myconfig;
1657 my $form = $main::form;
1659 my $dbh = $form->get_standard_dbh($myconfig);
1661 my $query = qq|SELECT * FROM parts WHERE id IN (| . join(', ', ('?') x scalar(@ids)) . qq|)|;
1663 my $info = selectall_hashref_query($form, $dbh, $query, map { conv_i($_) } @ids);
1665 if ('' eq ref $params{id}) {
1666 $info = $info->[0] || { };
1668 $main::lxdebug->leave_sub();
1672 my %info_map = map { $_->{id} => $_ } @{ $info };
1674 $main::lxdebug->leave_sub();
1679 sub prepare_parts_for_printing {
1680 $main::lxdebug->enter_sub();
1685 my $myconfig = \%main::myconfig;
1686 my $form = $main::form;
1688 my $dbh = $params{dbh} || $form->get_standard_dbh($myconfig);
1690 my $prefix = $params{prefix} || 'id_';
1691 my $rowcount = defined $params{rowcount} ? $params{rowcount} : $form->{rowcount};
1693 my @part_ids = keys %{ { map { $_ => 1 } grep { $_ } map { $form->{"${prefix}${_}"} } (1 .. $rowcount) } };
1696 $main::lxdebug->leave_sub();
1700 my $placeholders = join ', ', ('?') x scalar(@part_ids);
1701 my $query = qq|SELECT mm.parts_id, mm.model, mm.lastcost, v.name AS make
1703 LEFT JOIN vendor v ON (mm.make = v.id)
1704 WHERE mm.parts_id IN ($placeholders)|;
1708 my $sth = prepare_execute_query($form, $dbh, $query, @part_ids);
1710 while (my $ref = $sth->fetchrow_hashref()) {
1711 $makemodel{$ref->{parts_id}} ||= [];
1712 push @{ $makemodel{$ref->{parts_id}} }, $ref;
1717 my @columns = qw(ean image microfiche drawing weight);
1719 $query = qq|SELECT id, | . join(', ', @columns) . qq|
1721 WHERE id IN ($placeholders)|;
1723 my %data = selectall_as_map($form, $dbh, $query, 'id', \@columns, @part_ids);
1725 map { $form->{TEMPLATE_ARRAYS}{$_} = [] } (qw(make model), @columns);
1727 foreach my $i (1 .. $rowcount) {
1728 my $id = $form->{"${prefix}${i}"};
1732 foreach (@columns) {
1733 push @{ $form->{TEMPLATE_ARRAYS}{$_} }, $data{$id}->{$_};
1736 push @{ $form->{TEMPLATE_ARRAYS}{make} }, [];
1737 push @{ $form->{TEMPLATE_ARRAYS}{model} }, [];
1739 next if (!$makemodel{$id});
1741 foreach my $ref (@{ $makemodel{$id} }) {
1742 map { push @{ $form->{TEMPLATE_ARRAYS}{$_}->[-1] }, $ref->{$_} } qw(make model);
1746 $main::lxdebug->leave_sub();