1 #====================================================================
4 # Based on SQL-Ledger Version 2.1.9
5 # Web http://www.lx-office.org
7 #=====================================================================
8 # SQL-Ledger Accounting
9 # Copyright (C) 1999-2003
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 #======================================================================
33 #======================================================================
45 $::lxdebug->enter_sub;
47 my ($self, @args) = @_;
50 $::lxdebug->leave_sub;
54 require SL::DB::TransferType;
56 require SL::DB::Employee;
57 require SL::DB::Inventory;
59 my $employee = SL::DB::Manager::Employee->find_by(login => $::form->{login});
60 my ($now) = selectrow_query($::form, $::form->get_standard_dbh, qq|SELECT current_date|);
61 my @directions = (undef, qw(out in transfer));
64 my ($transfer, $field, $class, @find_by) = @_;
66 @find_by = (description => $transfer->{$field}) unless @find_by;
68 if ($transfer->{$field} || $transfer->{"${field}_id"}) {
69 return ref $transfer->{$field} && $transfer->{$field}->isa($class) ? $transfer->{$field}
70 : $transfer->{$field} ? $class->_get_manager_class->find_by(@find_by)
71 : $class->_get_manager_class->find_by(id => $transfer->{"${field}_id"});
78 my $db = SL::DB::Inventory->new->db;
79 $db->do_transaction(sub{
80 while (my $transfer = shift @args) {
81 my ($trans_id) = selectrow_query($::form, $::form->get_standard_dbh, qq|SELECT nextval('id')|);
83 my $part = $objectify->($transfer, 'parts', 'SL::DB::Part');
84 my $unit = $objectify->($transfer, 'unit', 'SL::DB::Unit', name => $transfer->{unit});
85 my $qty = $transfer->{qty};
86 my $src_bin = $objectify->($transfer, 'src_bin', 'SL::DB::Bin');
87 my $dst_bin = $objectify->($transfer, 'dst_bin', 'SL::DB::Bin');
88 my $src_wh = $objectify->($transfer, 'src_warehouse', 'SL::DB::Warehouse');
89 my $dst_wh = $objectify->($transfer, 'dst_warehouse', 'SL::DB::Warehouse');
90 my $project = $objectify->($transfer, 'project', 'SL::DB::Project');
92 $src_wh ||= $src_bin->warehouse if $src_bin;
93 $dst_wh ||= $dst_bin->warehouse if $dst_bin;
95 my $direction = 0; # bit mask
96 $direction |= 1 if $src_bin;
97 $direction |= 2 if $dst_bin;
99 my $transfer_type = $objectify->($transfer, 'transfer_type', 'SL::DB::TransferType', direction => $directions[$direction],
100 description => $transfer->{transfer_type});
104 employee => $employee,
105 trans_type => $transfer_type,
107 trans_id => $trans_id,
108 shippingdate => !$transfer->{shippingdate} || $transfer->{shippingdate} eq 'current_date'
109 ? $now : $transfer->{shippingdate},
110 map { $_ => $transfer->{$_} } qw( chargenumber bestbefore oe_id orderitems_id comment),
114 $qty = $unit->convert_to($qty, $part->unit_obj);
117 $params{chargenumber} ||= '';
119 if ($direction & 1) {
120 SL::DB::Inventory->new(
122 warehouse => $src_wh,
128 if ($direction & 2) {
129 SL::DB::Inventory->new(
131 warehouse => $dst_wh->id,
135 # Standardlagerplatz in Stammdaten gleich mitverschieben
136 if (defined($transfer->{change_default_bin})){
137 my $part = SL::DB::Part->new(id => conv_i($transfer->{parts_id}))->load;
138 $part->update_attributes(warehouse_id => conv_i($transfer->{dst_warehouse_id}));
139 $part->update_attributes(bin_id => conv_i($transfer->{dst_bin_id}));
143 push @trans_ids, $trans_id;
146 $::form->error("Warehouse transfer error: " . join("\n", (split(/\n/, $db->error))[0..2]));
149 $::lxdebug->leave_sub;
154 sub transfer_assembly {
155 $main::lxdebug->enter_sub();
159 Common::check_params(\%params, qw(assembly_id dst_warehouse_id login qty unit dst_bin_id chargenumber bestbefore comment));
161 # my $maxcreate=WH->check_assembly_max_create(assembly_id =>$params{'assembly_id'}, dbh => $my_dbh);
163 my $myconfig = \%main::myconfig;
164 my $form = $main::form;
165 my $dbh = $params{dbh} || $form->get_standard_dbh($myconfig);
170 # ... Standard-Check oben Ende. Hier die eigentliche SQL-Abfrage
171 # select parts_id,qty from assembly where id=1064;
172 # Erweiterung für bug 935 am 23.4.09 -
173 # Erzeugnisse können Dienstleistungen enthalten, die ja nicht 'lagerbar' sind.
174 # select parts_id,qty from assembly inner join parts on assembly.parts_id = parts.id
175 # where assembly.id=1066 and inventory_accno_id IS NOT NULL;
177 # Erweiterung für bug 23.4.09 -2 Erzeugnisse in Erzeugnissen können nicht ausgelagert werden,
178 # wenn assembly nicht überprüft wird ...
179 # patch von joachim eingespielt 24.4.2009:
180 # my $query = qq|select parts_id,qty from assembly inner join parts
181 # on assembly.parts_id = parts.id where assembly.id = ? and
182 # (inventory_accno_id IS NOT NULL or parts.assembly = TRUE)|;
185 my $query = qq|select parts_id,qty from assembly inner join parts on assembly.parts_id = parts.id
186 where assembly.id = ? and (inventory_accno_id IS NOT NULL or parts.assembly = TRUE)|;
188 my $sth_part_qty_assembly = prepare_execute_query($form, $dbh, $query, $params{assembly_id});
190 # Hier wird das prepared Statement für die Schleife über alle Lagerplätze vorbereitet
191 my $transferPartSQL = qq|INSERT INTO inventory (parts_id, warehouse_id, bin_id, chargenumber, bestbefore, comment, employee_id, qty, trans_id, trans_type_id)
192 VALUES (?, ?, ?, ?, ?, ?, (SELECT id FROM employee WHERE login = ?), ?, nextval('id'),
193 (SELECT id FROM transfer_type WHERE direction = 'out' AND description = 'used'))|;
194 my $sthTransferPartSQL = prepare_query($form, $dbh, $transferPartSQL);
196 # der return-string für die fehlermeldung inkl. welche waren zum fertigen noch fehlen
198 my $kannNichtFertigen =""; # Falls leer dann erfolgreich
199 my $schleife_durchlaufen=0; # Falls die Schleife nicht ausgeführt wird -> Keine Einzelteile definiert. Bessere Idee? jan
200 while (my $hash_ref = $sth_part_qty_assembly->fetchrow_hashref()) { #Schleife für select parts_id,(...) from assembly
201 $schleife_durchlaufen=1; # Erzeugnis definiert
202 my $partsQTY = $hash_ref->{qty} * $params{qty}; # benötigte teile * anzahl erzeugnisse
203 my $currentPart_ID = $hash_ref->{parts_id};
205 # Überprüfen, ob diese Anzahl gefertigt werden kann
206 my $max_parts = $self->get_max_qty_parts(parts_id => $currentPart_ID, # $self->method() == this.method()
207 warehouse_id => $params{dst_warehouse_id});
209 if ($partsQTY > $max_parts){
210 # Gibt es hier ein Problem mit nicht "escapten" Zeichen?
211 # 25.4.09 Antwort: Ja. Aber erst wenn im Frontend die locales-Funktion aufgerufen wird
213 $kannNichtFertigen .= "Zum Fertigen fehlen:" . abs($partsQTY - $max_parts) .
214 " Einheiten der Ware:" . $self->get_part_description(parts_id => $currentPart_ID) .
215 ", um das Erzeugnis herzustellen. <br>"; # Konnte die Menge nicht mit der aktuellen Anzahl der Waren fertigen
216 next; # die weiteren Überprüfungen sind unnötig, daher das nächste elemente prüfen (genaue Ausgabe, was noch fehlt)
219 # Eine kurze Vorabfrage, um den Lagerplatz, Chargennummer und die Mindesthaltbarkeit zu bestimmen
220 # Offen: Die Summe über alle Lagerplätze wird noch nicht gebildet
221 # Gelöst: Wir haben vorher schon die Abfrage durchgeführt, ob wir fertigen können.
222 # Noch besser gelöst: Wir laufen durch alle benötigten Waren zum Fertigen und geben eine Rückmeldung an den Benutzer was noch fehlt
223 # und lösen den Rest dann so wie bei xplace im Barcode-Programm
224 # S.a. Kommentar im bin/mozilla-Code mb übernimmt und macht das in ordentlich
226 my $tempquery = qq|SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory
227 WHERE warehouse_id = ? AND parts_id = ? GROUP BY bin_id, chargenumber, bestbefore having SUM(qty)>0|;
228 my $tempsth = prepare_execute_query($form, $dbh, $tempquery, $params{dst_warehouse_id}, $currentPart_ID);
230 # Alle Werte zu dem einzelnen Artikel, die wir später auslagern
231 my $tmpPartsQTY = $partsQTY;
233 while (my $temphash_ref = $tempsth->fetchrow_hashref()) {
234 my $temppart_bin_id = $temphash_ref->{bin_id}; # kann man hier den quelllagerplatz beim verbauen angeben?
235 my $temppart_chargenumber = $temphash_ref->{chargenumber};
236 my $temppart_bestbefore = conv_date($temphash_ref->{bestbefore});
237 my $temppart_qty = $temphash_ref->{sum};
239 if ($tmpPartsQTY > $temppart_qty) { # wir haben noch mehr waren zum wegbuchen.
240 # Wir buchen den kompletten Lagerplatzbestand und zählen die Hilfsvariable runter
241 $tmpPartsQTY = $tmpPartsQTY - $temppart_qty;
242 $temppart_qty = $temppart_qty * -1; # TODO beim analyiseren des sql-trace, war dieser wert positiv,
243 # wenn * -1 als berechnung in der parameter-übergabe angegeben wird.
244 # Dieser Wert IST und BLEIBT positiv!! Hilfe.
245 # Liegt das daran, dass dieser Wert aus einem SQL-Statement stammt?
246 do_statement($form, $sthTransferPartSQL, $transferPartSQL, $currentPart_ID, $params{dst_warehouse_id},
247 $temppart_bin_id, $temppart_chargenumber, $temppart_bestbefore, 'Verbraucht für ' .
248 $self->get_part_description(parts_id => $params{assembly_id}), $params{login}, $temppart_qty);
250 # hier ist noch ein fehler am besten mit definierten erzeugnissen debuggen 02/2009 jb
251 # idee: ausbuch algorithmus mit rekursion lösen und an- und abschaltbar machen
252 # das problem könnte sein, dass strict nicht an war und sth global eine andere zuweisung bekam
253 # auf jeden fall war der internal-server-error nach aktivierung von strict und warnings plus ein paar my-definitionen weg
254 } else { # okay, wir haben weniger oder gleich Waren die wir wegbuchen müssen, wir können also aufhören
256 do_statement($form, $sthTransferPartSQL, $transferPartSQL, $currentPart_ID, $params{dst_warehouse_id},
257 $temppart_bin_id, $temppart_chargenumber, $temppart_bestbefore, 'Verbraucht für ' .
258 $self->get_part_description(parts_id => $params{assembly_id}), $params{login}, $tmpPartsQTY);
259 last; # beendet die schleife (springt zum letzten element)
261 } # ende while SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory WHERE warehouse_id
262 } #ende while select parts_id,qty from assembly where id = ?
264 if ($schleife_durchlaufen==0){ # falls die schleife nicht durchlaufen wurde, wurden auch
265 # keine einzelteile definiert
266 $kannNichtFertigen ="Für dieses Erzeugnis sind keine Einzelteile definiert.
267 Dementsprechend kann auch nichts hergestellt werden";
269 # gibt die Fehlermeldung zurück. A.) Keine Teile definiert
270 # B.) Artikel und Anzahl der fehlenden Teile/Dienstleistungen
271 if ($kannNichtFertigen) {
272 return $kannNichtFertigen;
275 # soweit alles gut. Jetzt noch die wirkliche Lagerbewegung für das Erzeugnis ausführen ...
276 my $transferAssemblySQL = qq|INSERT INTO inventory (parts_id, warehouse_id, bin_id, chargenumber, bestbefore,
277 comment, employee_id, qty, trans_id, trans_type_id)
278 VALUES (?, ?, ?, ?, ?, ?, (SELECT id FROM employee WHERE login = ?), ?, nextval('id'),
279 (SELECT id FROM transfer_type WHERE direction = 'in' AND description = 'stock'))|;
280 my $sthTransferAssemblySQL = prepare_query($form, $dbh, $transferAssemblySQL);
281 do_statement($form, $sthTransferAssemblySQL, $transferAssemblySQL, $params{assembly_id}, $params{dst_warehouse_id},
282 $params{dst_bin_id}, $params{chargenumber}, conv_date($params{bestbefore}), $params{comment}, $params{login}, $params{qty});
285 $main::lxdebug->leave_sub();
286 return 1; # Alles erfolgreich
289 sub get_warehouse_journal {
290 $main::lxdebug->enter_sub();
295 my $myconfig = \%main::myconfig;
296 my $form = $main::form;
298 my $all_units = AM->retrieve_units($myconfig, $form);
300 # connect to database
301 my $dbh = $form->get_standard_dbh($myconfig);
304 my (@filter_ary, @filter_vars, $joins, %select_tokens, %select);
306 if ($filter{warehouse_id}) {
307 push @filter_ary, "w1.id = ? OR w2.id = ?";
308 push @filter_vars, $filter{warehouse_id}, $filter{warehouse_id};
311 if ($filter{bin_id}) {
312 push @filter_ary, "b1.id = ? OR b2.id = ?";
313 push @filter_vars, $filter{bin_id}, $filter{bin_id};
316 if ($filter{partnumber}) {
317 push @filter_ary, "p.partnumber ILIKE ?";
318 push @filter_vars, '%' . $filter{partnumber} . '%';
321 if ($filter{description}) {
322 push @filter_ary, "(p.description ILIKE ?)";
323 push @filter_vars, '%' . $filter{description} . '%';
326 if ($filter{chargenumber}) {
327 push @filter_ary, "i1.chargenumber ILIKE ?";
328 push @filter_vars, '%' . $filter{chargenumber} . '%';
331 if ($form->{bestbefore}) {
332 push @filter_ary, "?::DATE = i1.bestbefore::DATE";
333 push @filter_vars, $form->{bestbefore};
336 if ($form->{fromdate}) {
337 push @filter_ary, "?::DATE <= i1.itime::DATE";
338 push @filter_vars, $form->{fromdate};
341 if ($form->{todate}) {
342 push @filter_ary, "?::DATE >= i1.itime::DATE";
343 push @filter_vars, $form->{todate};
346 if ($form->{l_employee}) {
350 # prepare qty comparison for later filtering
351 my ($f_qty_op, $f_qty, $f_qty_base_unit);
352 if ($filter{qty_op} && defined($filter{qty}) && $filter{qty_unit} && $all_units->{$filter{qty_unit}}) {
353 $f_qty_op = $filter{qty_op};
354 $f_qty = $filter{qty} * $all_units->{$filter{qty_unit}}->{factor};
355 $f_qty_base_unit = $all_units->{$filter{qty_unit}}->{base_unit};
358 map { $_ = "(${_})"; } @filter_ary;
360 # if of a property number or description is requested,
361 # automatically check the matching id too.
362 map { $form->{"l_${_}id"} = "Y" if ($form->{"l_${_}description"} || $form->{"l_${_}number"}); } qw(warehouse bin);
364 # customize shown entry for not available fields.
365 $filter{na} = '-' unless $filter{na};
367 # make order, search in $filter and $form
368 my $sort_col = $form->{sort};
369 my $sort_order = $form->{order};
371 $sort_col = $filter{sort} unless $sort_col;
372 $sort_order = ($sort_col = 'itime') unless $sort_col;
373 $sort_col = 'itime' if $sort_col eq 'date';
374 $sort_order = $filter{order} unless $sort_order;
375 my $sort_spec = "${sort_col} " . ($sort_order ? " DESC" : " ASC");
377 my $where_clause = @filter_ary ? join(" AND ", @filter_ary) . " AND " : '';
379 $select_tokens{'trans'} = {
380 "parts_id" => "i1.parts_id",
381 "qty" => "ABS(SUM(i1.qty))",
382 "partnumber" => "p.partnumber",
383 "partdescription" => "p.description",
384 "bindescription" => "b.description",
385 "chargenumber" => "i1.chargenumber",
386 "bestbefore" => "i1.bestbefore",
387 "warehousedescription" => "w.description",
388 "partunit" => "p.unit",
389 "bin_from" => "b1.description",
390 "bin_to" => "b2.description",
391 "warehouse_from" => "w1.description",
392 "warehouse_to" => "w2.description",
393 "comment" => "i1.comment",
394 "trans_type" => "tt.description",
395 "trans_id" => "i1.trans_id",
396 "oe_id" => "COALESCE(i1.oe_id, i2.oe_id)",
397 "date" => "i1.itime::DATE",
398 "itime" => "i1.itime",
399 "employee" => "e.name",
400 "projectnumber" => "COALESCE(pr.projectnumber, '$filter{na}')",
403 $select_tokens{'out'} = {
404 "bin_to" => "'$filter{na}'",
405 "warehouse_to" => "'$filter{na}'",
408 $select_tokens{'in'} = {
409 "bin_from" => "'$filter{na}'",
410 "warehouse_from" => "'$filter{na}'",
413 # build the select clauses.
414 # take all the requested ones from the first hash and overwrite them from the out/in hashes if present.
415 for my $i ('trans', 'out', 'in') {
416 $select{$i} = join ', ', map { +/^l_/; ($select_tokens{$i}{"$'"} || $select_tokens{'trans'}{"$'"}) . " AS r_$'" }
417 ( grep( { !/qty$/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form), qw(l_parts_id l_qty l_partunit l_itime) );
420 my $group_clause = join ", ", map { +/^l_/; "r_$'" }
421 ( grep( { !/qty$/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form), qw(l_parts_id l_partunit l_itime) );
423 $where_clause = defined($where_clause) ? $where_clause : '';
425 qq|SELECT DISTINCT $select{trans}
427 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
428 LEFT JOIN parts p ON i1.parts_id = p.id
429 LEFT JOIN bin b1 ON i1.bin_id = b1.id
430 LEFT JOIN bin b2 ON i2.bin_id = b2.id
431 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
432 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
433 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
434 LEFT JOIN project pr ON i1.project_id = pr.id
435 LEFT JOIN employee e ON i1.employee_id = e.id
436 WHERE $where_clause i2.qty = -i1.qty AND i2.qty > 0 AND
437 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 2 )
438 GROUP BY $group_clause
442 SELECT DISTINCT $select{out}
444 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
445 LEFT JOIN parts p ON i1.parts_id = p.id
446 LEFT JOIN bin b1 ON i1.bin_id = b1.id
447 LEFT JOIN bin b2 ON i2.bin_id = b2.id
448 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
449 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
450 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
451 LEFT JOIN project pr ON i1.project_id = pr.id
452 LEFT JOIN employee e ON i1.employee_id = e.id
453 WHERE $where_clause i1.qty < 0 AND
454 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 1 )
455 GROUP BY $group_clause
459 SELECT DISTINCT $select{in}
461 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
462 LEFT JOIN parts p ON i1.parts_id = p.id
463 LEFT JOIN bin b1 ON i1.bin_id = b1.id
464 LEFT JOIN bin b2 ON i2.bin_id = b2.id
465 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
466 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
467 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
468 LEFT JOIN project pr ON i1.project_id = pr.id
469 LEFT JOIN employee e ON i1.employee_id = e.id
470 WHERE $where_clause i1.qty > 0 AND
471 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 1 )
472 GROUP BY $group_clause
473 ORDER BY r_${sort_spec}|;
475 my $sth = prepare_execute_query($form, $dbh, $query, @filter_vars, @filter_vars, @filter_vars);
477 my ($h_oe_id, $q_oe_id);
478 if ($form->{l_oe_id}) {
481 CASE WHEN oe.quotation THEN oe.quonumber ELSE oe.ordnumber END AS number,
483 WHEN oe.customer_id IS NOT NULL AND COALESCE(oe.quotation, FALSE) THEN 'sales_quotation'
484 WHEN oe.customer_id IS NOT NULL AND NOT COALESCE(oe.quotation, FALSE) THEN 'sales_order'
485 WHEN oe.customer_id IS NULL AND COALESCE(oe.quotation, FALSE) THEN 'request_quotation'
486 ELSE 'purchase_order'
493 SELECT dord.id AS id, dord.donumber AS number,
495 WHEN dord.customer_id IS NULL THEN 'purchase_delivery_order'
496 ELSE 'sales_delivery_order'
498 FROM delivery_orders dord
503 SELECT ar.id AS id, ar.invnumber AS number, 'sales_invoice' AS type
509 SELECT ap.id AS id, ap.invnumber AS number, 'purchase_invoice' AS type
513 $h_oe_id = prepare_query($form, $dbh, $q_oe_id);
517 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
518 map { /^r_/; $ref->{"$'"} = $ref->{$_} } keys %$ref;
519 my $qty = $ref->{"qty"} * 1;
521 next unless ($qty > 0);
524 my $part_unit = $all_units->{$ref->{"partunit"}};
525 next unless ($part_unit && ($part_unit->{"base_unit"} eq $f_qty_base_unit));
526 $qty *= $part_unit->{"factor"};
527 next if (('=' eq $f_qty_op) && ($qty != $f_qty));
528 next if (('>=' eq $f_qty_op) && ($qty < $f_qty));
529 next if (('<=' eq $f_qty_op) && ($qty > $f_qty));
532 if ($h_oe_id && $ref->{oe_id}) {
533 do_statement($form, $h_oe_id, $q_oe_id, ($ref->{oe_id}) x 4);
534 $ref->{oe_id_info} = $h_oe_id->fetchrow_hashref() || {};
537 push @contents, $ref;
541 $h_oe_id->finish() if $h_oe_id;
543 $main::lxdebug->leave_sub();
549 # This sub is the primary function to retrieve information about items in warehouses.
550 # $filter is a hashref and supports the following keys:
551 # - warehouse_id - will return matches with this warehouse_id only
552 # - partnumber - will return only matches where the given string is a substring of the partnumber
553 # - partsid - will return matches with this parts_id only
554 # - description - will return only matches where the given string is a substring of the description
555 # - chargenumber - will return only matches where the given string is a substring of the chargenumber
556 # - bestbefore - will return only matches with this bestbefore date
557 # - ean - will return only matches where the given string is a substring of the ean as stored in the table parts (article)
558 # - charge_ids - must be an arrayref. will return contents with these ids only
559 # - expires_in - will only return matches that expire within the given number of days
560 # will also add a column named 'has_expired' containing if the match has already expired or not
561 # - hazardous - will return matches with the flag hazardous only
562 # - oil - will return matches with the flag oil only
563 # - qty, qty_op - quantity filter (more info to come)
564 # - sort, order_by - sorting (more to come)
565 # - reservation - will provide an extra column containing the amount reserved of this match
566 # note: reservation flag turns off warehouse_* or bin_* information. both together don't make sense, since reserved info is stored separately
568 sub get_warehouse_report {
569 $main::lxdebug->enter_sub();
574 my $myconfig = \%main::myconfig;
575 my $form = $main::form;
577 my $all_units = AM->retrieve_units($myconfig, $form);
579 # connect to database
580 my $dbh = $form->get_standard_dbh($myconfig);
583 my (@filter_ary, @filter_vars, @wh_bin_filter_ary, @wh_bin_filter_vars);
585 delete $form->{include_empty_bins} unless ($form->{l_warehousedescription} || $form->{l_bindescription});
587 if ($filter{warehouse_id}) {
588 push @wh_bin_filter_ary, "w.id = ?";
589 push @wh_bin_filter_vars, $filter{warehouse_id};
592 if ($filter{bin_id}) {
593 push @wh_bin_filter_ary, "b.id = ?";
594 push @wh_bin_filter_vars, $filter{bin_id};
597 push @filter_ary, @wh_bin_filter_ary;
598 push @filter_vars, @wh_bin_filter_vars;
600 if ($filter{partnumber}) {
601 push @filter_ary, "p.partnumber ILIKE ?";
602 push @filter_vars, '%' . $filter{partnumber} . '%';
605 if ($filter{description}) {
606 push @filter_ary, "p.description ILIKE ?";
607 push @filter_vars, '%' . $filter{description} . '%';
610 if ($filter{partsid}) {
611 push @filter_ary, "p.id = ?";
612 push @filter_vars, $filter{partsid};
615 if ($filter{chargenumber}) {
616 push @filter_ary, "i.chargenumber ILIKE ?";
617 push @filter_vars, '%' . $filter{chargenumber} . '%';
620 if ($form->{bestbefore}) {
621 push @filter_ary, "?::DATE = i.bestbefore::DATE";
622 push @filter_vars, $form->{bestbefore};
626 push @filter_ary, "p.ean ILIKE ?";
627 push @filter_vars, '%' . $filter{ean} . '%';
631 push @filter_ary, "i.itime <= ?";
632 push @filter_vars, $filter{date};
634 if (!$filter{include_invalid_warehouses}){
635 push @filter_ary, "NOT (w.invalid)";
638 # prepare qty comparison for later filtering
639 my ($f_qty_op, $f_qty, $f_qty_base_unit);
641 if ($filter{qty_op} && defined $filter{qty} && $filter{qty_unit} && $all_units->{$filter{qty_unit}}) {
642 $f_qty_op = $filter{qty_op};
643 $f_qty = $filter{qty} * $all_units->{$filter{qty_unit}}->{factor};
644 $f_qty_base_unit = $all_units->{$filter{qty_unit}}->{base_unit};
647 map { $_ = "(${_})"; } @filter_ary;
649 # if of a property number or description is requested,
650 # automatically check the matching id too.
651 map { $form->{"l_${_}id"} = "Y" if ($form->{"l_${_}description"} || $form->{"l_${_}number"}); } qw(warehouse bin);
653 # make order, search in $filter and $form
654 my $sort_col = $form->{sort};
655 my $sort_order = $form->{order};
657 $sort_col = $filter{sort} unless $sort_col;
658 # falls $sort_col gar nicht in dem Bericht aufgenommen werden soll,
659 # führt ein entsprechenes order by $sort_col zu einem SQL-Fehler
660 # entsprechend parts_id als default lassen, wenn $sort_col UND l_$sort_col
661 # vorhanden sind (bpsw. l_partnumber = 'Y', für in Bericht aufnehmen).
662 # S.a. Bug 1597 jb 12.5.2011
663 $sort_col = "parts_id" unless ($sort_col && $form->{"l_$sort_col"});
664 $sort_order = $filter{order} unless $sort_order;
665 $sort_col =~ s/ASC|DESC//; # kill stuff left in from previous queries
666 my $orderby = $sort_col;
667 my $sort_spec = "${sort_col} " . ($sort_order ? " DESC" : " ASC");
669 my $where_clause = join " AND ", ("1=1", @filter_ary);
671 my %select_tokens = (
672 "parts_id" => "i.parts_id",
673 "qty" => "SUM(i.qty)",
674 "warehouseid" => "i.warehouse_id",
675 "partnumber" => "p.partnumber",
676 "partdescription" => "p.description",
677 "bindescription" => "b.description",
679 "chargenumber" => "i.chargenumber",
680 "bestbefore" => "i.bestbefore",
682 "chargeid" => "c.id",
683 "warehousedescription" => "w.description",
684 "partunit" => "p.unit",
685 "stock_value" => "p.lastcost / COALESCE(pfac.factor, 1)",
687 my $select_clause = join ', ', map { +/^l_/; "$select_tokens{$'} AS $'" }
688 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
689 qw(l_parts_id l_qty l_partunit) );
691 my $group_clause = join ", ", map { +/^l_/; "$'" }
692 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
693 qw(l_parts_id l_partunit) );
696 "stock_value" => "LEFT JOIN price_factors pfac ON (p.price_factor_id = pfac.id)",
699 my $joins = join ' ', grep { $_ } map { +/^l_/; $join_tokens{"$'"} }
700 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
701 qw(l_parts_id l_qty l_partunit) );
704 qq|SELECT $select_clause
706 LEFT JOIN parts p ON i.parts_id = p.id
707 LEFT JOIN bin b ON i.bin_id = b.id
708 LEFT JOIN warehouse w ON i.warehouse_id = w.id
711 GROUP BY $group_clause
712 ORDER BY $sort_spec|;
714 my $sth = prepare_execute_query($form, $dbh, $query, @filter_vars);
716 my (%non_empty_bins, @all_fields, @contents);
718 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
720 my $qty = $ref->{qty};
722 next unless ($qty != 0);
725 my $part_unit = $all_units->{$ref->{partunit}};
726 next if (!$part_unit || ($part_unit->{base_unit} ne $f_qty_base_unit));
727 $qty *= $part_unit->{factor};
728 next if (('=' eq $f_qty_op) && ($qty != $f_qty));
729 next if (('>=' eq $f_qty_op) && ($qty < $f_qty));
730 next if (('<=' eq $f_qty_op) && ($qty > $f_qty));
733 if ($form->{include_empty_bins}) {
734 $non_empty_bins{$ref->{binid}} = 1;
735 @all_fields = keys %{ $ref } unless (@all_fields);
738 $ref->{stock_value} = ($ref->{stock_value} || 0) * $ref->{qty};
740 push @contents, $ref;
745 if ($form->{include_empty_bins}) {
748 w.id AS warehouseid, w.description AS warehousedescription,
749 b.id AS binid, b.description AS bindescription
751 LEFT JOIN warehouse w ON (b.warehouse_id = w.id)|;
753 @filter_ary = @wh_bin_filter_ary;
754 @filter_vars = @wh_bin_filter_vars;
756 my @non_empty_bin_ids = keys %non_empty_bins;
757 if (@non_empty_bin_ids) {
758 push @filter_ary, qq|NOT b.id IN (| . join(', ', map { '?' } @non_empty_bin_ids) . qq|)|;
759 push @filter_vars, @non_empty_bin_ids;
762 $query .= qq| WHERE | . join(' AND ', map { "($_)" } @filter_ary) if (@filter_ary);
764 $sth = prepare_execute_query($form, $dbh, $query, @filter_vars);
766 while (my $ref = $sth->fetchrow_hashref()) {
767 map { $ref->{$_} ||= "" } @all_fields;
768 push @contents, $ref;
772 if (grep { $orderby eq $_ } qw(bindescription warehousedescription)) {
773 @contents = sort { ($a->{$orderby} cmp $b->{$orderby}) * (($form->{order}) ? 1 : -1) } @contents;
777 $main::lxdebug->leave_sub();
783 $main::lxdebug->enter_sub();
785 my ($self, $qty_op) = @_;
787 if (!$qty_op || ($qty_op eq "dontcare")) {
788 $main::lxdebug->leave_sub();
792 if ($qty_op eq "atleast") {
794 } elsif ($qty_op eq "atmost") {
800 $main::lxdebug->leave_sub();
805 sub retrieve_transfer_types {
806 $main::lxdebug->enter_sub();
809 my $direction = shift;
811 my $myconfig = \%main::myconfig;
812 my $form = $main::form;
814 my $dbh = $form->get_standard_dbh($myconfig);
816 my $types = selectall_hashref_query($form, $dbh, qq|SELECT * FROM transfer_type WHERE direction = ? ORDER BY sortkey|, $direction);
818 $main::lxdebug->leave_sub();
823 sub get_basic_bin_info {
824 $main::lxdebug->enter_sub();
829 Common::check_params(\%params, qw(id));
831 my $myconfig = \%main::myconfig;
832 my $form = $main::form;
834 my $dbh = $params{dbh} || $form->get_standard_dbh();
836 my @ids = 'ARRAY' eq ref $params{id} ? @{ $params{id} } : ($params{id});
839 qq|SELECT b.id AS bin_id, b.description AS bin_description,
840 w.id AS warehouse_id, w.description AS warehouse_description
842 LEFT JOIN warehouse w ON (b.warehouse_id = w.id)
843 WHERE b.id IN (| . join(', ', ('?') x scalar(@ids)) . qq|)|;
845 my $result = selectall_hashref_query($form, $dbh, $query, map { conv_i($_) } @ids);
847 if ('' eq ref $params{id}) {
848 $result = $result->[0] || { };
849 $main::lxdebug->leave_sub();
854 $main::lxdebug->leave_sub();
856 return map { $_->{bin_id} => $_ } @{ $result };
859 # Eingabe: Teilenummer, Lagernummer (warehouse)
860 # Ausgabe: Die maximale Anzahl der Teile in diesem Lager
862 sub get_max_qty_parts {
863 $main::lxdebug->enter_sub();
868 Common::check_params(\%params, qw(parts_id warehouse_id)); #die brauchen wir
870 my $myconfig = \%main::myconfig;
871 my $form = $main::form;
873 my $dbh = $params{dbh} || $form->get_standard_dbh();
875 my $query = qq| SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory where parts_id = ? AND warehouse_id = ? GROUP BY bin_id, chargenumber, bestbefore|;
877 my $sth_QTY = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}, $params{warehouse_id}); #info: aufruf an DBUtils.pm
879 my $max_qty_parts = 0; #Initialisierung mit 0
880 while (my $ref = $sth_QTY->fetchrow_hashref()) { # wir laufen über alle Haltbarkeiten, chargen und Lagerorte (s.a. SQL-Query oben)
881 $max_qty_parts += $ref->{sum};
884 $main::lxdebug->leave_sub();
886 return $max_qty_parts;
890 # Eingabe: Teilenummer, Lagernummer (warehouse)
891 # Ausgabe: Die Beschreibung der Ware bzw. Erzeugnis
893 sub get_part_description {
894 $main::lxdebug->enter_sub();
899 Common::check_params(\%params, qw(parts_id)); #die brauchen wir
901 my $myconfig = \%main::myconfig;
902 my $form = $main::form;
904 my $dbh = $params{dbh} || $form->get_standard_dbh();
906 my $query = qq| SELECT partnumber, description FROM parts where id = ? |;
908 my $sth = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}); #info: aufruf zu DBUtils.pm
910 my $ref = $sth->fetchrow_hashref();
911 my $part_description = $ref->{partnumber} . " " . $ref->{description};
913 $main::lxdebug->leave_sub();
915 return $part_description;
918 # Eingabe: Teilenummer, Lagerplatz_Id (bin_id)
919 # Ausgabe: Die maximale Anzahl der Teile in diesem Lagerplatz
920 # Bzw. Fehler, falls Chargen oder bestbefore
921 # bei eingelagerten Teilen definiert sind.
923 sub get_max_qty_parts_bin {
924 $main::lxdebug->enter_sub();
929 Common::check_params(\%params, qw(parts_id bin_id)); #die brauchen wir
931 my $myconfig = \%main::myconfig;
932 my $form = $main::form;
934 my $dbh = $params{dbh} || $form->get_standard_dbh();
936 my $query = qq| SELECT SUM(qty), chargenumber, bestbefore FROM inventory where parts_id = ?
937 AND bin_id = ? GROUP BY chargenumber, bestbefore|;
939 my $sth_QTY = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}, $params{bin_id}); #info: aufruf an DBUtils.pm
941 my $max_qty_parts = 0; #Initialisierung mit 0
942 # falls derselbe artikel mehrmals eingelagert ist
943 # chargennummer, muss entsprechend händisch agiert werden
946 while (my $ref = $sth_QTY->fetchrow_hashref()) { # wir laufen über alle Haltbarkeiten und Chargen(s.a. SQL-Query oben)
947 $max_qty_parts += $ref->{sum};
949 if ($ref->{chargenumber} || $ref->{bestbefore}){
957 $main::lxdebug->leave_sub();
959 return ($max_qty_parts, $error);
968 SL::WH - Warehouse backend
973 WH->transfer(\%params);
977 Backend for lx-office warehousing functions.
981 =head2 transfer \%PARAMS, [ \%PARAMS, ... ]
983 This is the main function to manipulate warehouse contents. A typical transfer
989 transfer_type => 'transfer',
990 src_warehouse_id => 12,
992 dst_warehouse_id => 25,
996 It will generate an entry in inventory representing the transfer. Note that
997 parts_id, qty, and transfer_type are mandatory. Depending on the transfer_type
998 a destination or a src is mandatory.
1000 transfer accepts more than one transaction parameter, each being a hash ref. If
1001 more than one is supplied, it is guaranteed, that all are processed in the same
1004 Here is a full list of parameters. All "_id" parameters except oe and
1005 orderitems can be called without id with RDB objects as well.
1011 The id of the article transferred. Does not check if the article is a service.
1016 Quantity of the transaction. Mandatory.
1020 Unit of the transaction. Optional.
1024 =item transfer_type_id
1026 The type of transaction. The first version is a string describing the
1027 transaction (the types 'transfer' 'in' 'out' and a few others are present on
1028 every system), the id is the hard id of a transfer_type from the database.
1030 Depending of the direction of the transfer_type, source and/or destination must
1033 One of transfer_type or transfer_type_id is mandatory.
1035 =item src_warehouse_id
1039 Warehouse and bin from which to transfer. Mandatory in transfer and out
1040 directions. Ignored in in directions.
1042 =item dst_warehouse_id
1046 Warehouse and bin to which to transfer. Mandatory in transfer and in
1047 directions. Ignored in out directions.
1051 If given, the transfer will transfer only articles with this chargenumber.
1056 Reference to an orderitem for which this transfer happened. Optional
1060 Reference to an order for which this transfer happened. Optional
1064 An optional comment.
1068 An expiration date. Note that this is not by default used by C<warehouse_report>.