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., 51 Franklin Street, Fifth Floor, Boston,
30 #======================================================================
32 # Inventory Control backend
34 #======================================================================
39 use List::MoreUtils qw(all any uniq);
43 use SL::HTML::Restrict;
45 use SL::Util qw(trim);
47 use SL::Presenter::Part qw(type_abbreviation classification_abbreviation separate_abbreviation);
52 sub retrieve_buchungsgruppen {
53 $main::lxdebug->enter_sub();
55 my ($self, $myconfig, $form) = @_;
59 my $dbh = $form->get_standard_dbh;
62 $query = qq|SELECT id, description FROM buchungsgruppen ORDER BY sortkey|;
63 $form->{BUCHUNGSGRUPPEN} = selectall_hashref_query($form, $dbh, $query);
65 $main::lxdebug->leave_sub();
69 $main::lxdebug->enter_sub();
71 my ($self, $myconfig, $form) = @_;
73 my $i = $form->{assembly_rows};
75 my $where = qq|1 = 1|;
78 my %columns = ("partnumber" => "p", "description" => "p", "partsgroup" => "pg");
80 while (my ($column, $table) = each(%columns)) {
81 next unless ($form->{"${column}_$i"});
82 $where .= qq| AND ${table}.${column} ILIKE ?|;
83 push(@values, like($form->{"${column}_$i"}));
87 $where .= qq| AND NOT (p.id = ?)|;
88 push(@values, conv_i($form->{id}));
91 # Search for part ID overrides all other criteria.
92 if ($form->{"id_${i}"}) {
93 $where = qq|p.id = ?|;
94 @values = ($form->{"id_${i}"});
97 if ($form->{partnumber}) {
98 $where .= qq| ORDER BY p.partnumber|;
100 $where .= qq| ORDER BY p.description|;
104 qq|SELECT p.id, p.partnumber, p.description, p.sellprice,
106 p.weight, p.onhand, p.unit, pg.partsgroup, p.lastcost,
107 p.price_factor_id, pfac.factor AS price_factor, p.notes as longdescription
109 LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
110 LEFT JOIN price_factors pfac ON pfac.id = p.price_factor_id
112 $form->{item_list} = selectall_hashref_query($form, SL::DB->client->dbh, $query, @values);
114 $main::lxdebug->leave_sub();
119 # Warning, deep magic ahead.
120 # This function gets all parts from the database according to the filters specified
123 # sort revers - sorting field + direction
126 # simple filter strings (every one of those also has a column flag prefixed with 'l_' associated):
127 # partnumber ean description partsgroup microfiche drawing
130 # l_partnumber l_description l_listprice l_sellprice l_lastcost l_priceupdate l_weight l_unit l_rop l_image l_drawing l_microfiche l_partsgroup
134 # itemstatus = active | onhand | short | obsolete | orphaned
135 # searchitems = part | assembly | service
138 # make model - makemodel
139 # serialnumber transdatefrom transdateto - invoice/orderitems
140 # warehouse - warehouse
144 # bought sold onorder ordered rfq quoted - aggreg joins with invoices/orders
145 # l_linetotal l_subtotal - aggreg joins to display totals (complicated) - NOT IMPLEMENTED here, implementation at frontend
146 # l_soldtotal - aggreg join to display total of sold quantity
147 # onhand - as above, but masking the simple itemstatus results (doh!)
148 # short - NOT IMPLEMENTED as form filter, only as itemstatus option
149 # l_serialnumber - belonges to serialnumber filter
150 # l_deliverydate - displays deliverydate is sold etc. flags are active
151 # l_soldtotal - aggreg join to display total of sold quantity, works as long as there's no bullshit in soldtotal
154 # onhand - as above, but masking the simple itemstatus results (doh!)
156 # search by overrides of description
157 # soldtotal drops option default warehouse and bin
158 # soldtotal can not work if there are no documents checked
160 # disabled sanity checks and changes:
161 # - searchitems = assembly will no longer disable bought
162 # - searchitems = service will no longer disable make and model, although services don't have make/model, it doesn't break the query
163 # - itemstatus = orphaned will no longer disable onhand short bought sold onorder ordered rfq quoted transdate[from|to]
164 # - itemstatus = obsolete will no longer disable onhand, short
165 # - allow sorting by ean
166 # - serialnumber filter also works if l_serialnumber isn't ticked
167 # - sorting will now change sorting if the requested sorting column isn't checked and doesn't get checked as a side effect
170 $main::lxdebug->enter_sub();
172 my ($self, $myconfig, $form) = @_;
173 my $dbh = $form->get_standard_dbh($myconfig);
175 # sanity backend check
176 croak "Cannot combine soldtotal with default bin or default warehouse" if ($form->{l_soldtotal} && ($form->{l_bin} || $form->{l_warehouse}));
178 $form->{parts} = +{ };
179 $form->{soldtotal} = undef if $form->{l_soldtotal}; # security fix. top100 insists on putting strings in there...
181 my @simple_filters = qw(partnumber ean description partsgroup microfiche drawing onhand);
182 my @project_filters = qw(projectnumber projectdescription);
183 my @makemodel_filters = qw(make model);
184 my @invoice_oi_filters = qw(serialnumber soldtotal);
185 my @apoe_filters = qw(transdate);
186 my @like_filters = (@simple_filters, @invoice_oi_filters);
187 my @all_columns = (@simple_filters, @makemodel_filters, @apoe_filters, @project_filters, qw(serialnumber));
188 my @simple_l_switches = (@all_columns, qw(notes listprice sellprice lastcost priceupdate weight unit rop image shop insertdate));
189 my %no_simple_l_switches = (warehouse => 'wh.description as warehouse', bin => 'bin.description as bin');
190 my @oe_flags = qw(bought sold onorder ordered rfq quoted);
191 my @qsooqr_flags = qw(invnumber ordnumber quonumber trans_id name module qty);
192 my @deliverydate_flags = qw(deliverydate);
193 # my @other_flags = qw(onhand); # ToDO: implement these
194 # my @inactive_flags = qw(l_subtotal short l_linetotal);
196 my @select_tokens = qw(id factor part_type classification_id);
197 my @where_tokens = qw(1=1);
198 my @group_tokens = ();
200 my %joins_needed = ();
203 partsgroup => 'LEFT JOIN partsgroup pg ON (pg.id = p.partsgroup_id)',
204 makemodel => 'LEFT JOIN makemodel mm ON (mm.parts_id = p.id)',
205 pfac => 'LEFT JOIN price_factors pfac ON (pfac.id = p.price_factor_id)',
208 SELECT parts_id, description, serialnumber, trans_id, unit, sellprice, qty, assemblyitem, deliverydate, 'invoice' AS ioi, project_id, id FROM invoice UNION
209 SELECT parts_id, description, serialnumber, trans_id, unit, sellprice, qty, FALSE AS assemblyitem, NULL AS deliverydate, 'orderitems' AS ioi, project_id, id FROM orderitems
210 ) AS ioi ON ioi.parts_id = p.id|,
213 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
214 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
215 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
216 ) AS apoe ON ((ioi.trans_id = apoe.id) AND (ioi.ioi = apoe.ioi))|,
219 SELECT id, name, 'customer' AS cv FROM customer UNION
220 SELECT id, name, 'vendor' AS cv FROM vendor
221 ) AS cv ON cv.id = apoe.customer_id OR cv.id = apoe.vendor_id|,
222 mv => 'LEFT JOIN vendor AS mv ON mv.id = mm.make',
223 project => 'LEFT JOIN project AS pj ON pj.id = COALESCE(ioi.project_id, apoe.globalproject_id)',
224 warehouse => 'LEFT JOIN warehouse AS wh ON wh.id = p.warehouse_id',
225 bin => 'LEFT JOIN bin ON bin.id = p.bin_id',
227 my @join_order = qw(partsgroup makemodel mv invoice_oi apoe cv pfac project warehouse bin);
230 deliverydate => 'apoe.', serialnumber => 'ioi.',
231 transdate => 'apoe.', trans_id => 'ioi.',
232 module => 'apoe.', name => 'cv.',
233 ordnumber => 'apoe.', make => 'mm.',
234 quonumber => 'apoe.', model => 'mm.',
235 invnumber => 'apoe.', partsgroup => 'pg.',
236 lastcost => 'p.', , soldtotal => ' ',
237 factor => 'pfac.', projectnumber => 'pj.',
238 'SUM(ioi.qty)' => ' ', projectdescription => 'pj.',
241 serialnumber => 'ioi.',
242 quotation => 'apoe.',
248 # if the join condition in these blocks are met, the column
249 # of the specified table will gently override (coalesce actually) the original value
250 # use it to conditionally coalesce values from subtables
251 my @column_override = (
252 # column name, prefix, joins_needed, nick name (in case column is named like another)
253 [ 'description', 'ioi.', 'invoice_oi' ],
254 [ 'deliverydate', 'ioi.', 'invoice_oi' ],
255 [ 'transdate', 'apoe.', 'apoe' ],
256 [ 'unit', 'ioi.', 'invoice_oi' ],
257 [ 'sellprice', 'ioi.', 'invoice_oi' ],
260 # careful with renames. these are HARD, and any filters done on the original column will break
261 my %renamed_columns = (
262 'factor' => 'price_factor',
263 'SUM(ioi.qty)' => 'soldtotal',
264 'ioi.id' => 'ioi_id',
266 'projectdescription' => 'projectdescription',
267 'insertdate' => 'insertdate',
271 projectdescription => 'description',
272 insertdate => 'itime::DATE',
275 my $make_token_builder = sub {
276 my $joins_needed = shift;
278 my ($nick, $alias) = @_;
279 my ($col) = $real_column{$nick} || $nick;
280 my @coalesce_tokens =
281 map { ($_->[1] || 'p.') . $_->[0] }
282 grep { !$_->[2] || $joins_needed->{$_->[2]} }
283 grep { ($_->[3] || $_->[0]) eq $nick }
284 @column_override, [ $col, $table_prefix{$nick}, undef , $nick ];
286 my $coalesce = scalar @coalesce_tokens > 1;
288 ? sprintf 'COALESCE(%s)', join ', ', @coalesce_tokens
289 : shift @coalesce_tokens)
290 . ($alias && ($coalesce || $renamed_columns{$nick})
291 ? " AS " . ($renamed_columns{$nick} || $nick)
296 #===== switches and simple filters ========#
298 # special case transdate
299 if (grep { trim($form->{$_}) } qw(transdatefrom transdateto)) {
300 $form->{"l_transdate"} = 1;
301 push @select_tokens, 'transdate';
302 for (qw(transdatefrom transdateto)) {
303 my $value = trim($form->{$_});
305 push @where_tokens, sprintf "transdate %s ?", /from$/ ? '>=' : '<=';
306 push @bind_vars, $value;
310 # special case smart search
312 $form->{"l_$_"} = 1 for qw(partnumber description unit sellprice lastcost linetotal);
313 $form->{l_service} = 1 if $form->{searchitems} eq 'service' || $form->{searchitems} eq '';
314 $form->{l_assembly} = 1 if $form->{searchitems} eq 'assembly' || $form->{searchitems} eq '';
315 $form->{l_part} = 1 if $form->{searchitems} eq 'part' || $form->{searchitems} eq '';
316 $form->{l_assortment} = 1 if $form->{searchitems} eq 'assortment' || $form->{searchitems} eq '';
317 push @where_tokens, "p.partnumber ILIKE ? OR p.description ILIKE ?";
318 push @bind_vars, (like($form->{all})) x 2;
321 # special case insertdate
322 if (grep { trim($form->{$_}) } qw(insertdatefrom insertdateto)) {
323 $form->{"l_insertdate"} = 1;
324 push @select_tokens, 'insertdate';
326 my $token_builder = $make_token_builder->();
327 my $token = $token_builder->('insertdate');
329 for (qw(insertdatefrom insertdateto)) {
330 my $value = trim($form->{$_});
332 push @where_tokens, sprintf "$token %s ?", /from$/ ? '>=' : '<=';
333 push @bind_vars, $value;
337 if ($form->{"partsgroup_id"}) {
338 $form->{"l_partsgroup"} = '1'; # show the column
339 push @where_tokens, "pg.id = ?";
340 push @bind_vars, $form->{"partsgroup_id"};
343 if ($form->{shop} ne '') {
344 $form->{l_shop} = '1'; # show the column
345 if ($form->{shop} eq '0' || $form->{shop} eq 'f') {
346 push @where_tokens, 'NOT p.shop';
349 push @where_tokens, 'p.shop';
353 foreach (@like_filters) {
354 next unless $form->{$_};
355 $form->{"l_$_"} = '1'; # show the column
356 push @where_tokens, "$table_prefix{$_}$_ ILIKE ?";
357 push @bind_vars, like($form->{$_});
360 foreach (@simple_l_switches) {
361 next unless $form->{"l_$_"};
362 push @select_tokens, $_;
365 # Oder Bedingungen fuer Ware Dienstleistung Erzeugnis:
366 if ($form->{l_part} || $form->{l_assembly} || $form->{l_service} || $form->{l_assortment}) {
368 push @or_tokens, "p.part_type = 'service'" if $form->{l_service};
369 push @or_tokens, "p.part_type = 'assembly'" if $form->{l_assembly};
370 push @or_tokens, "p.part_type = 'part'" if $form->{l_part};
371 push @or_tokens, "p.part_type = 'assortment'" if $form->{l_assortment};
372 push @where_tokens, join ' OR ', map { "($_)" } @or_tokens;
376 push @where_tokens, q|'F' = 'T'|;
379 if ( $form->{classification_id} > 0 ) {
380 push @where_tokens, "p.classification_id = ?";
381 push @bind_vars, $form->{classification_id};
384 for ($form->{itemstatus}) {
385 push @where_tokens, 'p.id NOT IN
386 (SELECT DISTINCT parts_id FROM invoice UNION
387 SELECT DISTINCT parts_id FROM assembly UNION
388 SELECT DISTINCT parts_id FROM orderitems)' if /orphaned/;
389 push @where_tokens, 'p.onhand = 0' if /orphaned/;
390 push @where_tokens, 'NOT p.obsolete' if /active/;
391 push @where_tokens, ' p.obsolete', if /obsolete/;
392 push @where_tokens, 'p.onhand > 0', if /onhand/;
393 push @where_tokens, 'p.onhand < p.rop', if /short/;
396 my $q_assembly_lastcost =
397 qq|(SELECT SUM(a_lc.qty * p_lc.lastcost / COALESCE(pfac_lc.factor, 1))
399 LEFT JOIN parts p_lc ON (a_lc.parts_id = p_lc.id)
400 LEFT JOIN price_factors pfac_lc ON (p_lc.price_factor_id = pfac_lc.id)
401 WHERE (a_lc.id = p.id)) AS assembly_lastcost|;
402 $table_prefix{$q_assembly_lastcost} = ' ';
404 # special case makemodel search
405 # all_parts is based upon the assumption that every parameter is named like the column it represents
406 # unfortunately make would have to match vendor.name which is already taken for vendor.name in bsooqr mode.
407 # fortunately makemodel doesn't need to be displayed later, so adding a special clause to where_token is sufficient.
409 push @where_tokens, 'mv.name ILIKE ?';
410 push @bind_vars, like($form->{make});
412 if ($form->{model}) {
413 push @where_tokens, 'mm.model ILIKE ?';
414 push @bind_vars, like($form->{model});
417 # special case: sorting by partnumber
418 # since partnumbers are expected to be prefixed integers, a special sorting is implemented sorting first lexically by prefix and then by suffix.
419 # and yes, that expression is designed to hold that array of regexes only once, so the map is kinda messy, sorry about that.
420 # ToDO: implement proper functional sorting
421 # Nette Idee von Sven, gibt aber Probleme wenn die Artikelnummern groesser als 32bit sind. Korrekt waere es, dass Sort-Natural-Modul zu nehmen
422 # Ich lass das mal hier drin, damit die Idee erhalten bleibt jb 28.5.2009 bug 1018
423 #$form->{sort} = join ', ', map { push @select_tokens, $_; ($table_prefix{$_} = "substring(partnumber,'[") . $_ } qw|^[:digit:]]+') [:digit:]]+')::INTEGER|
424 # if $form->{sort} eq 'partnumber';
426 #my $order_clause = " ORDER BY $form->{sort} $sort_order";
429 $limit_clause = " LIMIT 100" if $form->{top100};
430 $limit_clause = " LIMIT " . $form->{limit} * 1 if $form->{limit} * 1;
432 #=== joins and complicated filters ========#
434 my $bsooqr = any { $form->{$_} } @oe_flags;
435 my @bsooqr_tokens = ();
437 push @select_tokens, @qsooqr_flags, 'quotation', 'cv', 'ioi.id', 'ioi.ioi' if $bsooqr;
438 push @select_tokens, @deliverydate_flags if $bsooqr && $form->{l_deliverydate};
439 push @select_tokens, $q_assembly_lastcost if $form->{l_assembly} && $form->{l_lastcost};
440 push @bsooqr_tokens, q|module = 'ir' AND NOT ioi.assemblyitem| if $form->{bought};
441 push @bsooqr_tokens, q|module = 'is' AND NOT ioi.assemblyitem| if $form->{sold};
442 push @bsooqr_tokens, q|module = 'oe' AND NOT quotation AND cv = 'customer'| if $form->{ordered};
443 push @bsooqr_tokens, q|module = 'oe' AND NOT quotation AND cv = 'vendor'| if $form->{onorder};
444 push @bsooqr_tokens, q|module = 'oe' AND quotation AND cv = 'customer'| if $form->{quoted};
445 push @bsooqr_tokens, q|module = 'oe' AND quotation AND cv = 'vendor'| if $form->{rfq};
446 push @where_tokens, join ' OR ', map { "($_)" } @bsooqr_tokens if $bsooqr;
448 $joins_needed{partsgroup} = 1;
449 $joins_needed{pfac} = 1;
450 $joins_needed{project} = 1 if grep { $form->{$_} || $form->{"l_$_"} } @project_filters;
451 $joins_needed{makemodel} = 1 if grep { $form->{$_} || $form->{"l_$_"} } @makemodel_filters;
452 $joins_needed{mv} = 1 if $joins_needed{makemodel};
453 $joins_needed{cv} = 1 if $bsooqr;
454 $joins_needed{apoe} = 1 if $joins_needed{project} || $joins_needed{cv} || grep { $form->{$_} || $form->{"l_$_"} } @apoe_filters;
455 $joins_needed{invoice_oi} = 1 if $joins_needed{project} || $joins_needed{apoe} || grep { $form->{$_} || $form->{"l_$_"} } @invoice_oi_filters;
456 $joins_needed{bin} = 1 if $form->{l_bin};
457 $joins_needed{warehouse} = 1 if $form->{l_warehouse};
459 # special case for description search.
460 # up in the simple filter section the description filter got interpreted as something like: WHERE description ILIKE '%$form->{description}%'
461 # now we'd like to search also for the masked description entered in orderitems and invoice, so...
462 # find the old entries in of @where_tokens and @bind_vars, and adjust them
463 if ($joins_needed{invoice_oi}) {
464 for (my ($wi, $bi) = (0)x2; $wi <= $#where_tokens; $bi++ if $where_tokens[$wi++] =~ /\?/) {
465 next unless $where_tokens[$wi] =~ /\bdescription ILIKE/;
466 splice @where_tokens, $wi, 1, 'p.description ILIKE ? OR ioi.description ILIKE ?';
467 splice @bind_vars, $bi, 0, $bind_vars[$bi];
472 # now the master trick: soldtotal.
473 if ($form->{l_soldtotal}) {
474 push @where_tokens, 'NOT ioi.qty = 0';
475 push @group_tokens, @select_tokens;
476 map { s/.*\sAS\s+//si } @group_tokens;
477 push @select_tokens, 'SUM(ioi.qty)';
480 #============= build query ================#
482 my $token_builder = $make_token_builder->(\%joins_needed);
484 my @sort_cols = (@simple_filters, qw(id onhand invnumber ordnumber quonumber name serialnumber soldtotal deliverydate insertdate shop));
485 $form->{sort} = 'id' unless grep { $form->{"l_$_"} } grep { $form->{sort} eq $_ } @sort_cols; # sort by id if unknown or invisible column
486 my $sort_order = ($form->{revers} ? ' DESC' : ' ASC');
487 my $order_clause = " ORDER BY " . $token_builder->($form->{sort}) . ($form->{revers} ? ' DESC' : ' ASC');
489 my $select_clause = join ', ', map { $token_builder->($_, 1) } @select_tokens;
490 my $join_clause = join ' ', @joins{ grep $joins_needed{$_}, @join_order };
491 my $where_clause = join ' AND ', map { "($_)" } @where_tokens;
492 my $group_clause = @group_tokens ? ' GROUP BY ' . join ', ', map { $token_builder->($_) } @group_tokens : '';
494 # key of %no_simple_l_switch is the logical l_switch.
495 # the assigned value is the 'not so simple
497 my $no_simple_select_clause;
498 foreach my $no_simple_l_switch (keys %no_simple_l_switches) {
499 next unless $form->{"l_${no_simple_l_switch}"};
500 $no_simple_select_clause .= ', '. $no_simple_l_switches{$no_simple_l_switch};
502 $select_clause .= $no_simple_select_clause;
504 my %oe_flag_to_cvar = (
507 onorder => 'orderitems',
508 ordered => 'orderitems',
510 quoted => 'orderitems',
513 my ($cvar_where, @cvar_values) = CVar->build_filter_query(
515 trans_id_field => $bsooqr ? 'ioi.id': 'p.id',
517 sub_module => $bsooqr ? [ uniq grep { $oe_flag_to_cvar{$form->{$_}} } @oe_flags ] : undef,
521 $where_clause .= qq| AND ($cvar_where)|;
522 push @bind_vars, @cvar_values;
525 # simple search for assemblies by items used in assemblies
526 if ($form->{bom} eq '2' && $form->{l_assembly}) {
527 # assembly_qty is the column name
528 $form->{l_assembly_qty} = 1;
529 # nuke where clause and bind vars
530 $where_clause = ' 1=1 AND p.id in (SELECT id from assembly where parts_id IN ' .
531 ' (select id from parts where 1=1';
533 # use only like filter for items used in assemblies
534 foreach (@like_filters) {
535 next unless $form->{$_};
536 $form->{"l_$_"} = '1'; # show the column
537 $where_clause .= " AND $_ ILIKE ? ";
538 push @bind_vars, like($form->{$_});
540 $where_clause .='))';
543 my $query = <<" SQL";
544 SELECT DISTINCT $select_clause
552 $form->{parts} = selectall_hashref_query($form, $dbh, $query, @bind_vars);
554 map { $_->{onhand} *= 1 } @{ $form->{parts} };
556 # fix qty sign in ap. those are saved negative
557 if ($bsooqr && $form->{bought}) {
558 for my $row (@{ $form->{parts} }) {
559 $row->{qty} *= -1 if $row->{module} eq 'ir';
563 # post processing for assembly parts lists (bom)
564 # for each part get the assembly parts and add them into the partlist.
566 if ($form->{l_assembly} && $form->{bom}) {
568 qq|SELECT p.id, p.partnumber, p.description, a.qty AS assembly_qty,
569 p.unit, p.notes, p.itime::DATE as insertdate,
570 p.sellprice, p.listprice, p.lastcost,
572 p.image, p.drawing, p.microfiche,
575 INNER JOIN assembly a ON (p.id = a.parts_id)
578 my $sth = prepare_query($form, $dbh, $query);
580 foreach my $item (@{ $form->{parts} }) {
581 push(@assemblies, $item);
582 do_statement($form, $sth, $query, conv_i($item->{id}));
584 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
585 $ref->{assemblyitem} = 1;
586 map { $ref->{$_} /= $ref->{factor} || 1 } qw(sellprice listprice lastcost);
587 push(@assemblies, $ref);
592 # copy assemblies to $form->{parts}
593 $form->{parts} = \@assemblies;
596 if ($form->{l_pricegroups} ) {
598 SELECT parts_id, price, pricegroup_id
603 my $sth = prepare_query($form, $dbh, $query);
605 foreach my $part (@{ $form->{parts} }) {
606 do_statement($form, $sth, $query, conv_i($part->{id}));
608 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
609 $part->{"pricegroup_$ref->{pricegroup_id}"} = $ref->{price};
615 $main::lxdebug->leave_sub();
617 return $form->{parts};
620 # get partnumber, description, unit, sellprice and soldtotal with choice through $sortorder for Top100
622 $main::lxdebug->enter_sub();
624 my ($self, $myconfig, $form, $sortorder) = @_;
625 my $dbh = $form->get_standard_dbh;
626 my $order = qq| p.partnumber|;
627 my $where = qq|1 = 1|;
630 if ($sortorder eq "all") {
631 $where .= qq| AND (partnumber ILIKE ?) AND (description ILIKE ?)|;
632 push(@values, like($form->{partnumber}), like($form->{description}));
634 } elsif ($sortorder eq "partnumber") {
635 $where .= qq| AND (partnumber ILIKE ?)|;
636 push(@values, like($form->{partnumber}));
638 } elsif ($sortorder eq "description") {
639 $where .= qq| AND (description ILIKE ?)|;
640 push(@values, like($form->{description}));
641 $order = "description";
646 qq|SELECT id, partnumber, description, unit, sellprice,
649 WHERE $where ORDER BY $order|;
651 my $sth = prepare_execute_query($form, $dbh, $query, @values);
654 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
655 if (($ref->{partnumber} eq "*") && ($ref->{description} eq "")) {
660 $form->{"type_and_classific_$j"} = type_abbreviation($ref->{part_type}).
661 classification_abbreviation($ref->{classification_id});
662 $form->{"id_$j"} = $ref->{id};
663 $form->{"partnumber_$j"} = $ref->{partnumber};
664 $form->{"description_$j"} = $ref->{description};
665 $form->{"unit_$j"} = $ref->{unit};
666 $form->{"sellprice_$j"} = $ref->{sellprice};
667 $form->{"soldtotal_$j"} = get_soldtotal($dbh, $ref->{id});
672 $main::lxdebug->leave_sub();
677 # gets sum of sold part with part_id
679 $main::lxdebug->enter_sub();
683 my $query = qq|SELECT sum(qty) FROM invoice WHERE parts_id = ?|;
684 my ($sum) = selectrow_query($main::form, $dbh, $query, conv_i($id));
687 $main::lxdebug->leave_sub();
692 sub follow_account_chain {
693 $main::lxdebug->enter_sub(2);
695 my ($self, $form, $dbh, $transdate, $accno_id, $accno) = @_;
697 my @visited_accno_ids = ($accno_id);
701 $form->{ACCOUNT_CHAIN_BY_ID} ||= {
702 map { $_->{id} => $_ }
703 selectall_hashref_query($form, $dbh, <<SQL, $transdate) };
704 SELECT c.id, c.new_chart_id, date(?) >= c.valid_from AS is_valid, cnew.accno
706 LEFT JOIN chart cnew ON c.new_chart_id = cnew.id
707 WHERE NOT c.new_chart_id IS NULL AND (c.new_chart_id > 0)
711 my $ref = $form->{ACCOUNT_CHAIN_BY_ID}->{$accno_id};
712 last unless ($ref && $ref->{"is_valid"} &&
713 !grep({ $_ == $ref->{"new_chart_id"} } @visited_accno_ids));
714 $accno_id = $ref->{"new_chart_id"};
715 $accno = $ref->{"accno"};
716 push(@visited_accno_ids, $accno_id);
719 $main::lxdebug->leave_sub(2);
721 return ($accno_id, $accno);
724 sub retrieve_accounts {
725 $main::lxdebug->enter_sub;
728 my $myconfig = shift;
730 my $dbh = $form->get_standard_dbh;
731 my %args = @_; # index => part_id
733 $form->{taxzone_id} *= 1;
735 return unless grep $_, values %args; # shortfuse if no part_id supplied
739 if (($form->{type} eq "invoice") or ($form->{type} eq "credit_note") or ($form->{script} eq 'ir.pl')) {
740 # use deliverydate for sales and purchase invoice, if it exists
741 # also use deliverydate for credit notes
742 $transdate = $form->{tax_point} || $form->{deliverydate} || $form->{invdate};
745 $deliverydate = $form->{reqdate} if any { $_ eq $form->{type} } qw(sales_order request_quotation purchase_order);
746 $transdate = $form->{tax_point} || $deliverydate || $form->{transdate};
749 if ($transdate eq "") {
750 $transdate = DateTime->today_local->to_lxoffice;
752 $transdate = $dbh->quote($transdate);
755 my $inc_exp = $form->{"vc"} eq "customer" ? "income_accno_id" : "expense_accno_id";
757 my @part_ids = grep { $_ } values %args;
758 my $in = join ',', ('?') x @part_ids;
760 my %accno_by_part = map { $_->{id} => $_ }
761 selectall_hashref_query($form, $dbh, <<SQL, @part_ids);
764 bg.inventory_accno_id,
765 tc.income_accno_id AS income_accno_id,
766 tc.expense_accno_id AS expense_accno_id,
767 c1.accno AS inventory_accno,
768 c2.accno AS income_accno,
769 c3.accno AS expense_accno
771 LEFT JOIN buchungsgruppen bg ON p.buchungsgruppen_id = bg.id
772 LEFT JOIN taxzone_charts tc on bg.id = tc.buchungsgruppen_id
773 LEFT JOIN chart c1 ON bg.inventory_accno_id = c1.id
774 LEFT JOIN chart c2 ON tc.income_accno_id = c2.id
775 LEFT JOIN chart c3 ON tc.expense_accno_id = c3.id
777 tc.taxzone_id = '$form->{taxzone_id}'
782 my $query_tax = <<SQL;
783 SELECT c.accno, t.taxdescription AS description, t.id as tax_id, t.rate,
786 LEFT JOIN chart c ON c.id = t.chart_id
790 WHERE tk.chart_id = ? AND startdate <= ?
791 ORDER BY startdate DESC LIMIT 1)
793 my $sth_tax = prepare_query($::form, $dbh, $query_tax);
795 while (my ($index => $part_id) = each %args) {
796 my $ref = $accno_by_part{$part_id} or next;
798 $ref->{"inventory_accno_id"} = undef unless $ref->{"part_type"} eq 'part';
801 for my $type (qw(inventory income expense)) {
802 next unless $ref->{"${type}_accno_id"};
803 ($accounts{"${type}_accno_id"}, $accounts{"${type}_accno"}) =
804 $self->follow_account_chain($form, $dbh, $transdate, $ref->{"${type}_accno_id"}, $ref->{"${type}_accno"});
807 $form->{"${_}_accno_$index"} = $accounts{"${_}_accno"} for qw(inventory income expense);
809 $sth_tax->execute($accounts{$inc_exp}, quote_db_date($transdate)) || $::form->dberror($query_tax);
810 $ref = $sth_tax->fetchrow_hashref or next;
812 $form->{"taxaccounts_$index"} = $ref->{"accno"};
813 $form->{"taxaccounts"} .= "$ref->{accno} "if $form->{"taxaccounts"} !~ /$ref->{accno}/;
815 $form->{"$ref->{accno}_${_}"} = $ref->{$_} for qw(rate description taxnumber tax_id);
820 $::lxdebug->leave_sub;
823 sub get_basic_part_info {
824 $main::lxdebug->enter_sub();
829 Common::check_params(\%params, qw(id));
831 my @ids = 'ARRAY' eq ref $params{id} ? @{ $params{id} } : ($params{id});
834 $main::lxdebug->leave_sub();
838 my $myconfig = \%main::myconfig;
839 my $form = $main::form;
841 my $dbh = $form->get_standard_dbh($myconfig);
843 my $query = qq|SELECT * FROM parts WHERE id IN (| . join(', ', ('?') x scalar(@ids)) . qq|)|;
845 my $info = selectall_hashref_query($form, $dbh, $query, map { conv_i($_) } @ids);
847 if ('' eq ref $params{id}) {
848 $info = $info->[0] || { };
850 $main::lxdebug->leave_sub();
854 my %info_map = map { $_->{id} => $_ } @{ $info };
856 $main::lxdebug->leave_sub();
861 sub prepare_parts_for_printing {
862 $main::lxdebug->enter_sub();
867 my $myconfig = $params{myconfig} || \%main::myconfig;
868 my $form = $params{form} || $main::form;
870 my $dbh = $params{dbh} || $form->get_standard_dbh($myconfig);
872 my $prefix = $params{prefix} || 'id_';
873 my $rowcount = defined $params{rowcount} ? $params{rowcount} : $form->{rowcount};
875 my @part_ids = keys %{ { map { $_ => 1 } grep { $_ } map { $form->{"${prefix}${_}"} } (1 .. $rowcount) } };
878 $main::lxdebug->leave_sub();
882 my $placeholders = join ', ', ('?') x scalar(@part_ids);
883 my $query = qq|SELECT mm.parts_id, mm.model, mm.lastcost, v.name AS make
885 LEFT JOIN vendor v ON (mm.make = v.id)
886 WHERE mm.parts_id IN ($placeholders)|;
890 my $sth = prepare_execute_query($form, $dbh, $query, @part_ids);
892 while (my $ref = $sth->fetchrow_hashref()) {
893 $makemodel{$ref->{parts_id}} ||= [];
894 push @{ $makemodel{$ref->{parts_id}} }, $ref;
901 cp.customer_partnumber AS customer_model,
902 c.name AS customer_make
903 FROM part_customer_prices cp
904 LEFT JOIN customer c ON (cp.customer_id = c.id)
905 WHERE cp.parts_id IN ($placeholders)|;
907 my %customermodel = ();
909 $sth = prepare_execute_query($form, $dbh, $query, @part_ids);
911 while (my $ref = $sth->fetchrow_hashref()) {
912 $customermodel{$ref->{parts_id}} ||= [];
913 push @{ $customermodel{$ref->{parts_id}} }, $ref;
918 my @columns = qw(ean image microfiche drawing);
920 $query = qq|SELECT id, | . join(', ', @columns) . qq|
922 WHERE id IN ($placeholders)|;
924 my %data = selectall_as_map($form, $dbh, $query, 'id', \@columns, @part_ids);
927 map { $template_arrays{$_} = [] } (qw(make model customer_make customer_model), @columns);
929 foreach my $i (1 .. $rowcount) {
930 my $id = $form->{"${prefix}${i}"};
935 push @{ $template_arrays{$_} }, $data{$id}->{$_};
938 push @{ $template_arrays{make} }, [];
939 push @{ $template_arrays{model} }, [];
941 if ($makemodel{$id}) {
942 foreach my $ref (@{ $makemodel{$id} }) {
943 map { push @{ $template_arrays{$_}->[-1] }, $ref->{$_} } qw(make model);
947 push @{ $template_arrays{customer_make} }, [];
948 push @{ $template_arrays{customer_model} }, [];
950 if ($customermodel{$id}) {
951 foreach my $ref (@{ $customermodel{$id} }) {
952 push @{ $template_arrays{$_}->[-1] }, $ref->{$_} for qw(customer_make customer_model);
958 my $parts = SL::DB::Manager::Part->get_all(query => [ id => \@part_ids ]);
959 my %parts_by_id = map { $_->id => $_ } @$parts;
961 for my $i (1..$rowcount) {
962 my $id = $form->{"${prefix}${i}"};
964 my $prt = $parts_by_id{$id};
965 my $type_abbr = type_abbreviation($prt->part_type);
966 push @{ $template_arrays{part_type} }, $prt->part_type;
967 push @{ $template_arrays{part_abbreviation} }, $type_abbr;
968 push @{ $template_arrays{type_and_classific}}, $type_abbr . classification_abbreviation($prt->classification_id);
969 push @{ $template_arrays{separate} }, separate_abbreviation($prt->classification_id);
972 $main::lxdebug->leave_sub();
973 return %template_arrays;