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 #======================================================================
48 $::lxdebug->enter_sub;
50 my ($self, @args) = @_;
53 $::lxdebug->leave_sub;
57 require SL::DB::TransferType;
59 require SL::DB::Employee;
60 require SL::DB::Inventory;
62 my $employee = SL::DB::Manager::Employee->find_by(login => $::form->{login});
63 my ($now) = selectrow_query($::form, $::form->get_standard_dbh, qq|SELECT current_date|);
64 my @directions = (undef, qw(out in transfer));
67 my ($transfer, $field, $class, @find_by) = @_;
69 @find_by = (description => $transfer->{$field}) unless @find_by;
71 if ($transfer->{$field} || $transfer->{"${field}_id"}) {
72 return ref $transfer->{$field} && $transfer->{$field}->isa($class) ? $transfer->{$field}
73 : $transfer->{$field} ? $class->_get_manager_class->find_by(@find_by)
74 : $class->_get_manager_class->find_by(id => $transfer->{"${field}_id"});
81 my $db = SL::DB::Inventory->new->db;
82 $db->do_transaction(sub{
83 while (my $transfer = shift @args) {
84 my ($trans_id) = selectrow_query($::form, $::form->get_standard_dbh, qq|SELECT nextval('id')|);
86 my $part = $objectify->($transfer, 'parts', 'SL::DB::Part');
87 my $unit = $objectify->($transfer, 'unit', 'SL::DB::Unit', name => $transfer->{unit});
88 my $qty = $transfer->{qty};
89 my $src_bin = $objectify->($transfer, 'src_bin', 'SL::DB::Bin');
90 my $dst_bin = $objectify->($transfer, 'dst_bin', 'SL::DB::Bin');
91 my $src_wh = $objectify->($transfer, 'src_warehouse', 'SL::DB::Warehouse');
92 my $dst_wh = $objectify->($transfer, 'dst_warehouse', 'SL::DB::Warehouse');
93 my $project = $objectify->($transfer, 'project', 'SL::DB::Project');
95 $src_wh ||= $src_bin->warehouse if $src_bin;
96 $dst_wh ||= $dst_bin->warehouse if $dst_bin;
98 my $direction = 0; # bit mask
99 $direction |= 1 if $src_bin;
100 $direction |= 2 if $dst_bin;
102 my $transfer_type = $objectify->($transfer, 'transfer_type', 'SL::DB::TransferType', direction => $directions[$direction],
103 description => $transfer->{transfer_type});
107 employee => $employee,
108 trans_type => $transfer_type,
110 trans_id => $trans_id,
111 shippingdate => !$transfer->{shippingdate} || $transfer->{shippingdate} eq 'current_date'
112 ? $now : $transfer->{shippingdate},
113 map { $_ => $transfer->{$_} } qw( chargenumber bestbefore oe_id orderitems_id comment),
117 $qty = $unit->convert_to($qty, $part->unit_obj);
120 $params{chargenumber} ||= '';
122 if ($direction & 1) {
123 SL::DB::Inventory->new(
125 warehouse => $src_wh,
131 if ($direction & 2) {
132 SL::DB::Inventory->new(
134 warehouse => $dst_wh->id,
138 # Standardlagerplatz in Stammdaten gleich mitverschieben
139 if (defined($transfer->{change_default_bin})){
140 my $part = SL::DB::Part->new(id => conv_i($transfer->{parts_id}))->load;
141 $part->update_attributes(warehouse_id => conv_i($transfer->{dst_warehouse_id}));
142 $part->update_attributes(bin_id => conv_i($transfer->{dst_bin_id}));
146 push @trans_ids, $trans_id;
149 $::form->error("Warehouse transfer error: " . join("\n", (split(/\n/, $db->error))[0..2]));
152 $::lxdebug->leave_sub;
157 sub transfer_assembly {
158 $main::lxdebug->enter_sub();
162 Common::check_params(\%params, qw(assembly_id dst_warehouse_id login qty unit dst_bin_id chargenumber bestbefore comment));
165 my $unit = SL::DB::Manager::Unit->find_by(name => $params{unit});
167 my $assembly = SL::DB::Manager::Assembly->get_all(
168 query => [ id => $params{assembly_id} ],
169 with_objects => ['part'],
172 $params{qty} = $unit->convert_to($params{qty}, $assembly->part->unit_obj);
175 # my $maxcreate=WH->check_assembly_max_create(assembly_id =>$params{'assembly_id'}, dbh => $my_dbh);
177 my $myconfig = \%main::myconfig;
178 my $form = $main::form;
179 my $dbh = $params{dbh} || $form->get_standard_dbh($myconfig);
184 # ... Standard-Check oben Ende. Hier die eigentliche SQL-Abfrage
185 # select parts_id,qty from assembly where id=1064;
186 # Erweiterung für bug 935 am 23.4.09 -
187 # Erzeugnisse können Dienstleistungen enthalten, die ja nicht 'lagerbar' sind.
188 # select parts_id,qty from assembly inner join parts on assembly.parts_id = parts.id
189 # where assembly.id=1066 and inventory_accno_id IS NOT NULL;
191 # Erweiterung für bug 23.4.09 -2 Erzeugnisse in Erzeugnissen können nicht ausgelagert werden,
192 # wenn assembly nicht überprüft wird ...
193 # patch von joachim eingespielt 24.4.2009:
194 # my $query = qq|select parts_id,qty from assembly inner join parts
195 # on assembly.parts_id = parts.id where assembly.id = ? and
196 # (inventory_accno_id IS NOT NULL or parts.assembly = TRUE)|;
199 my $query = qq|select parts_id,qty from assembly inner join parts on assembly.parts_id = parts.id
200 where assembly.id = ? and (inventory_accno_id IS NOT NULL or parts.assembly = TRUE)|;
202 my $sth_part_qty_assembly = prepare_execute_query($form, $dbh, $query, $params{assembly_id});
204 # Hier wird das prepared Statement für die Schleife über alle Lagerplätze vorbereitet
205 my $transferPartSQL = qq|INSERT INTO inventory (parts_id, warehouse_id, bin_id, chargenumber, bestbefore, comment, employee_id, qty, trans_id, trans_type_id)
206 VALUES (?, ?, ?, ?, ?, ?, (SELECT id FROM employee WHERE login = ?), ?, nextval('id'),
207 (SELECT id FROM transfer_type WHERE direction = 'out' AND description = 'used'))|;
208 my $sthTransferPartSQL = prepare_query($form, $dbh, $transferPartSQL);
210 # der return-string für die fehlermeldung inkl. welche waren zum fertigen noch fehlen
212 my $kannNichtFertigen =""; # Falls leer dann erfolgreich
213 my $schleife_durchlaufen=0; # Falls die Schleife nicht ausgeführt wird -> Keine Einzelteile definiert. Bessere Idee? jan
214 while (my $hash_ref = $sth_part_qty_assembly->fetchrow_hashref()) { #Schleife für select parts_id,(...) from assembly
215 $schleife_durchlaufen=1; # Erzeugnis definiert
216 my $partsQTY = $hash_ref->{qty} * $params{qty}; # benötigte teile * anzahl erzeugnisse
217 my $currentPart_ID = $hash_ref->{parts_id};
219 # Überprüfen, ob diese Anzahl gefertigt werden kann
220 my $max_parts = $self->get_max_qty_parts(parts_id => $currentPart_ID, # $self->method() == this.method()
221 warehouse_id => $params{dst_warehouse_id});
223 if ($partsQTY > $max_parts){
224 # Gibt es hier ein Problem mit nicht "escapten" Zeichen?
225 # 25.4.09 Antwort: Ja. Aber erst wenn im Frontend die locales-Funktion aufgerufen wird
227 $kannNichtFertigen .= "Zum Fertigen fehlen:" . abs($partsQTY - $max_parts) .
228 " Einheiten der Ware:" . $self->get_part_description(parts_id => $currentPart_ID) .
229 ", um das Erzeugnis herzustellen. <br>"; # Konnte die Menge nicht mit der aktuellen Anzahl der Waren fertigen
230 next; # die weiteren Überprüfungen sind unnötig, daher das nächste elemente prüfen (genaue Ausgabe, was noch fehlt)
233 # Eine kurze Vorabfrage, um den Lagerplatz, Chargennummer und die Mindesthaltbarkeit zu bestimmen
234 # Offen: Die Summe über alle Lagerplätze wird noch nicht gebildet
235 # Gelöst: Wir haben vorher schon die Abfrage durchgeführt, ob wir fertigen können.
236 # Noch besser gelöst: Wir laufen durch alle benötigten Waren zum Fertigen und geben eine Rückmeldung an den Benutzer was noch fehlt
237 # und lösen den Rest dann so wie bei xplace im Barcode-Programm
238 # S.a. Kommentar im bin/mozilla-Code mb übernimmt und macht das in ordentlich
240 my $tempquery = qq|SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory
241 WHERE warehouse_id = ? AND parts_id = ? GROUP BY bin_id, chargenumber, bestbefore having SUM(qty)>0|;
242 my $tempsth = prepare_execute_query($form, $dbh, $tempquery, $params{dst_warehouse_id}, $currentPart_ID);
244 # Alle Werte zu dem einzelnen Artikel, die wir später auslagern
245 my $tmpPartsQTY = $partsQTY;
247 while (my $temphash_ref = $tempsth->fetchrow_hashref()) {
248 my $temppart_bin_id = $temphash_ref->{bin_id}; # kann man hier den quelllagerplatz beim verbauen angeben?
249 my $temppart_chargenumber = $temphash_ref->{chargenumber};
250 my $temppart_bestbefore = conv_date($temphash_ref->{bestbefore});
251 my $temppart_qty = $temphash_ref->{sum};
253 if ($tmpPartsQTY > $temppart_qty) { # wir haben noch mehr waren zum wegbuchen.
254 # Wir buchen den kompletten Lagerplatzbestand und zählen die Hilfsvariable runter
255 $tmpPartsQTY = $tmpPartsQTY - $temppart_qty;
256 $temppart_qty = $temppart_qty * -1; # TODO beim analyiseren des sql-trace, war dieser wert positiv,
257 # wenn * -1 als berechnung in der parameter-übergabe angegeben wird.
258 # Dieser Wert IST und BLEIBT positiv!! Hilfe.
259 # Liegt das daran, dass dieser Wert aus einem SQL-Statement stammt?
260 do_statement($form, $sthTransferPartSQL, $transferPartSQL, $currentPart_ID, $params{dst_warehouse_id},
261 $temppart_bin_id, $temppart_chargenumber, $temppart_bestbefore, 'Verbraucht für ' .
262 $self->get_part_description(parts_id => $params{assembly_id}), $params{login}, $temppart_qty);
264 # hier ist noch ein fehler am besten mit definierten erzeugnissen debuggen 02/2009 jb
265 # idee: ausbuch algorithmus mit rekursion lösen und an- und abschaltbar machen
266 # das problem könnte sein, dass strict nicht an war und sth global eine andere zuweisung bekam
267 # auf jeden fall war der internal-server-error nach aktivierung von strict und warnings plus ein paar my-definitionen weg
268 } else { # okay, wir haben weniger oder gleich Waren die wir wegbuchen müssen, wir können also aufhören
270 do_statement($form, $sthTransferPartSQL, $transferPartSQL, $currentPart_ID, $params{dst_warehouse_id},
271 $temppart_bin_id, $temppart_chargenumber, $temppart_bestbefore, 'Verbraucht für ' .
272 $self->get_part_description(parts_id => $params{assembly_id}), $params{login}, $tmpPartsQTY);
273 last; # beendet die schleife (springt zum letzten element)
275 } # ende while SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory WHERE warehouse_id
276 } #ende while select parts_id,qty from assembly where id = ?
278 if ($schleife_durchlaufen==0){ # falls die schleife nicht durchlaufen wurde, wurden auch
279 # keine einzelteile definiert
280 $kannNichtFertigen ="Für dieses Erzeugnis sind keine Einzelteile definiert.
281 Dementsprechend kann auch nichts hergestellt werden";
283 # gibt die Fehlermeldung zurück. A.) Keine Teile definiert
284 # B.) Artikel und Anzahl der fehlenden Teile/Dienstleistungen
285 if ($kannNichtFertigen) {
286 return $kannNichtFertigen;
289 # soweit alles gut. Jetzt noch die wirkliche Lagerbewegung für das Erzeugnis ausführen ...
290 my $transferAssemblySQL = qq|INSERT INTO inventory (parts_id, warehouse_id, bin_id, chargenumber, bestbefore,
291 comment, employee_id, qty, trans_id, trans_type_id)
292 VALUES (?, ?, ?, ?, ?, ?, (SELECT id FROM employee WHERE login = ?), ?, nextval('id'),
293 (SELECT id FROM transfer_type WHERE direction = 'in' AND description = 'stock'))|;
294 my $sthTransferAssemblySQL = prepare_query($form, $dbh, $transferAssemblySQL);
295 do_statement($form, $sthTransferAssemblySQL, $transferAssemblySQL, $params{assembly_id}, $params{dst_warehouse_id},
296 $params{dst_bin_id}, $params{chargenumber}, conv_date($params{bestbefore}), $params{comment}, $params{login}, $params{qty});
299 $main::lxdebug->leave_sub();
300 return 1; # Alles erfolgreich
303 sub get_warehouse_journal {
304 $main::lxdebug->enter_sub();
309 my $myconfig = \%main::myconfig;
310 my $form = $main::form;
312 my $all_units = AM->retrieve_units($myconfig, $form);
314 # connect to database
315 my $dbh = $form->get_standard_dbh($myconfig);
318 my (@filter_ary, @filter_vars, $joins, %select_tokens, %select);
320 if ($filter{warehouse_id}) {
321 push @filter_ary, "w1.id = ? OR w2.id = ?";
322 push @filter_vars, $filter{warehouse_id}, $filter{warehouse_id};
325 if ($filter{bin_id}) {
326 push @filter_ary, "b1.id = ? OR b2.id = ?";
327 push @filter_vars, $filter{bin_id}, $filter{bin_id};
330 if ($filter{partnumber}) {
331 push @filter_ary, "p.partnumber ILIKE ?";
332 push @filter_vars, '%' . $filter{partnumber} . '%';
335 if ($filter{description}) {
336 push @filter_ary, "(p.description ILIKE ?)";
337 push @filter_vars, '%' . $filter{description} . '%';
340 if ($filter{chargenumber}) {
341 push @filter_ary, "i1.chargenumber ILIKE ?";
342 push @filter_vars, '%' . $filter{chargenumber} . '%';
345 if ($form->{bestbefore}) {
346 push @filter_ary, "?::DATE = i1.bestbefore::DATE";
347 push @filter_vars, $form->{bestbefore};
350 if ($form->{fromdate}) {
351 push @filter_ary, "?::DATE <= i1.itime::DATE";
352 push @filter_vars, $form->{fromdate};
355 if ($form->{todate}) {
356 push @filter_ary, "?::DATE >= i1.itime::DATE";
357 push @filter_vars, $form->{todate};
360 if ($form->{l_employee}) {
364 # prepare qty comparison for later filtering
365 my ($f_qty_op, $f_qty, $f_qty_base_unit);
366 if ($filter{qty_op} && defined($filter{qty}) && $filter{qty_unit} && $all_units->{$filter{qty_unit}}) {
367 $f_qty_op = $filter{qty_op};
368 $f_qty = $filter{qty} * $all_units->{$filter{qty_unit}}->{factor};
369 $f_qty_base_unit = $all_units->{$filter{qty_unit}}->{base_unit};
372 map { $_ = "(${_})"; } @filter_ary;
374 # if of a property number or description is requested,
375 # automatically check the matching id too.
376 map { $form->{"l_${_}id"} = "Y" if ($form->{"l_${_}description"} || $form->{"l_${_}number"}); } qw(warehouse bin);
378 # customize shown entry for not available fields.
379 $filter{na} = '-' unless $filter{na};
381 # make order, search in $filter and $form
382 my $sort_col = $form->{sort};
383 my $sort_order = $form->{order};
385 $sort_col = $filter{sort} unless $sort_col;
386 $sort_order = ($sort_col = 'itime') unless $sort_col;
387 $sort_col = 'itime' if $sort_col eq 'date';
388 $sort_order = $filter{order} unless $sort_order;
389 my $sort_spec = "${sort_col} " . ($sort_order ? " DESC" : " ASC");
391 my $where_clause = @filter_ary ? join(" AND ", @filter_ary) . " AND " : '';
393 $select_tokens{'trans'} = {
394 "parts_id" => "i1.parts_id",
395 "qty" => "ABS(SUM(i1.qty))",
396 "partnumber" => "p.partnumber",
397 "partdescription" => "p.description",
398 "bindescription" => "b.description",
399 "chargenumber" => "i1.chargenumber",
400 "bestbefore" => "i1.bestbefore",
401 "warehousedescription" => "w.description",
402 "partunit" => "p.unit",
403 "bin_from" => "b1.description",
404 "bin_to" => "b2.description",
405 "warehouse_from" => "w1.description",
406 "warehouse_to" => "w2.description",
407 "comment" => "i1.comment",
408 "trans_type" => "tt.description",
409 "trans_id" => "i1.trans_id",
410 "oe_id" => "COALESCE(i1.oe_id, i2.oe_id)",
411 "date" => "i1.itime::DATE",
412 "itime" => "i1.itime",
413 "employee" => "e.name",
414 "projectnumber" => "COALESCE(pr.projectnumber, '$filter{na}')",
417 $select_tokens{'out'} = {
418 "bin_to" => "'$filter{na}'",
419 "warehouse_to" => "'$filter{na}'",
422 $select_tokens{'in'} = {
423 "bin_from" => "'$filter{na}'",
424 "warehouse_from" => "'$filter{na}'",
427 # build the select clauses.
428 # take all the requested ones from the first hash and overwrite them from the out/in hashes if present.
429 for my $i ('trans', 'out', 'in') {
430 $select{$i} = join ', ', map { +/^l_/; ($select_tokens{$i}{"$'"} || $select_tokens{'trans'}{"$'"}) . " AS r_$'" }
431 ( grep( { !/qty$/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form), qw(l_parts_id l_qty l_partunit l_itime) );
434 my $group_clause = join ", ", map { +/^l_/; "r_$'" }
435 ( grep( { !/qty$/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form), qw(l_parts_id l_partunit l_itime) );
437 $where_clause = defined($where_clause) ? $where_clause : '';
439 qq|SELECT DISTINCT $select{trans}
441 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
442 LEFT JOIN parts p ON i1.parts_id = p.id
443 LEFT JOIN bin b1 ON i1.bin_id = b1.id
444 LEFT JOIN bin b2 ON i2.bin_id = b2.id
445 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
446 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
447 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
448 LEFT JOIN project pr ON i1.project_id = pr.id
449 LEFT JOIN employee e ON i1.employee_id = e.id
450 WHERE $where_clause i2.qty = -i1.qty AND i2.qty > 0 AND
451 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 2 )
452 GROUP BY $group_clause
456 SELECT DISTINCT $select{out}
458 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
459 LEFT JOIN parts p ON i1.parts_id = p.id
460 LEFT JOIN bin b1 ON i1.bin_id = b1.id
461 LEFT JOIN bin b2 ON i2.bin_id = b2.id
462 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
463 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
464 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
465 LEFT JOIN project pr ON i1.project_id = pr.id
466 LEFT JOIN employee e ON i1.employee_id = e.id
467 WHERE $where_clause i1.qty < 0 AND
468 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 1 )
469 GROUP BY $group_clause
473 SELECT DISTINCT $select{in}
475 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
476 LEFT JOIN parts p ON i1.parts_id = p.id
477 LEFT JOIN bin b1 ON i1.bin_id = b1.id
478 LEFT JOIN bin b2 ON i2.bin_id = b2.id
479 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
480 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
481 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
482 LEFT JOIN project pr ON i1.project_id = pr.id
483 LEFT JOIN employee e ON i1.employee_id = e.id
484 WHERE $where_clause i1.qty > 0 AND
485 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 1 )
486 GROUP BY $group_clause
487 ORDER BY r_${sort_spec}|;
489 my $sth = prepare_execute_query($form, $dbh, $query, @filter_vars, @filter_vars, @filter_vars);
491 my ($h_oe_id, $q_oe_id);
492 if ($form->{l_oe_id}) {
495 CASE WHEN oe.quotation THEN oe.quonumber ELSE oe.ordnumber END AS number,
497 WHEN oe.customer_id IS NOT NULL AND COALESCE(oe.quotation, FALSE) THEN 'sales_quotation'
498 WHEN oe.customer_id IS NOT NULL AND NOT COALESCE(oe.quotation, FALSE) THEN 'sales_order'
499 WHEN oe.customer_id IS NULL AND COALESCE(oe.quotation, FALSE) THEN 'request_quotation'
500 ELSE 'purchase_order'
507 SELECT dord.id AS id, dord.donumber AS number,
509 WHEN dord.customer_id IS NULL THEN 'purchase_delivery_order'
510 ELSE 'sales_delivery_order'
512 FROM delivery_orders dord
517 SELECT ar.id AS id, ar.invnumber AS number, 'sales_invoice' AS type
523 SELECT ap.id AS id, ap.invnumber AS number, 'purchase_invoice' AS type
527 $h_oe_id = prepare_query($form, $dbh, $q_oe_id);
531 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
532 map { /^r_/; $ref->{"$'"} = $ref->{$_} } keys %$ref;
533 my $qty = $ref->{"qty"} * 1;
535 next unless ($qty > 0);
538 my $part_unit = $all_units->{$ref->{"partunit"}};
539 next unless ($part_unit && ($part_unit->{"base_unit"} eq $f_qty_base_unit));
540 $qty *= $part_unit->{"factor"};
541 next if (('=' eq $f_qty_op) && ($qty != $f_qty));
542 next if (('>=' eq $f_qty_op) && ($qty < $f_qty));
543 next if (('<=' eq $f_qty_op) && ($qty > $f_qty));
546 if ($h_oe_id && $ref->{oe_id}) {
547 do_statement($form, $h_oe_id, $q_oe_id, ($ref->{oe_id}) x 4);
548 $ref->{oe_id_info} = $h_oe_id->fetchrow_hashref() || {};
551 push @contents, $ref;
555 $h_oe_id->finish() if $h_oe_id;
557 $main::lxdebug->leave_sub();
563 # This sub is the primary function to retrieve information about items in warehouses.
564 # $filter is a hashref and supports the following keys:
565 # - warehouse_id - will return matches with this warehouse_id only
566 # - partnumber - will return only matches where the given string is a substring of the partnumber
567 # - partsid - will return matches with this parts_id only
568 # - description - will return only matches where the given string is a substring of the description
569 # - chargenumber - will return only matches where the given string is a substring of the chargenumber
570 # - bestbefore - will return only matches with this bestbefore date
571 # - ean - will return only matches where the given string is a substring of the ean as stored in the table parts (article)
572 # - charge_ids - must be an arrayref. will return contents with these ids only
573 # - expires_in - will only return matches that expire within the given number of days
574 # will also add a column named 'has_expired' containing if the match has already expired or not
575 # - hazardous - will return matches with the flag hazardous only
576 # - oil - will return matches with the flag oil only
577 # - qty, qty_op - quantity filter (more info to come)
578 # - sort, order_by - sorting (more to come)
579 # - reservation - will provide an extra column containing the amount reserved of this match
580 # note: reservation flag turns off warehouse_* or bin_* information. both together don't make sense, since reserved info is stored separately
582 sub get_warehouse_report {
583 $main::lxdebug->enter_sub();
588 my $myconfig = \%main::myconfig;
589 my $form = $main::form;
591 my $all_units = AM->retrieve_units($myconfig, $form);
593 # connect to database
594 my $dbh = $form->get_standard_dbh($myconfig);
597 my (@filter_ary, @filter_vars, @wh_bin_filter_ary, @wh_bin_filter_vars);
599 delete $form->{include_empty_bins} unless ($form->{l_warehousedescription} || $form->{l_bindescription});
601 if ($filter{warehouse_id}) {
602 push @wh_bin_filter_ary, "w.id = ?";
603 push @wh_bin_filter_vars, $filter{warehouse_id};
606 if ($filter{bin_id}) {
607 push @wh_bin_filter_ary, "b.id = ?";
608 push @wh_bin_filter_vars, $filter{bin_id};
611 push @filter_ary, @wh_bin_filter_ary;
612 push @filter_vars, @wh_bin_filter_vars;
614 if ($filter{partnumber}) {
615 push @filter_ary, "p.partnumber ILIKE ?";
616 push @filter_vars, '%' . $filter{partnumber} . '%';
619 if ($filter{description}) {
620 push @filter_ary, "p.description ILIKE ?";
621 push @filter_vars, '%' . $filter{description} . '%';
624 if ($filter{partsid}) {
625 push @filter_ary, "p.id = ?";
626 push @filter_vars, $filter{partsid};
629 if ($filter{chargenumber}) {
630 push @filter_ary, "i.chargenumber ILIKE ?";
631 push @filter_vars, '%' . $filter{chargenumber} . '%';
634 if ($form->{bestbefore}) {
635 push @filter_ary, "?::DATE = i.bestbefore::DATE";
636 push @filter_vars, $form->{bestbefore};
640 push @filter_ary, "p.ean ILIKE ?";
641 push @filter_vars, '%' . $filter{ean} . '%';
645 push @filter_ary, "i.itime <= ?";
646 push @filter_vars, $filter{date};
648 if (!$filter{include_invalid_warehouses}){
649 push @filter_ary, "NOT (w.invalid)";
652 # prepare qty comparison for later filtering
653 my ($f_qty_op, $f_qty, $f_qty_base_unit);
655 if ($filter{qty_op} && defined $filter{qty} && $filter{qty_unit} && $all_units->{$filter{qty_unit}}) {
656 $f_qty_op = $filter{qty_op};
657 $f_qty = $filter{qty} * $all_units->{$filter{qty_unit}}->{factor};
658 $f_qty_base_unit = $all_units->{$filter{qty_unit}}->{base_unit};
661 map { $_ = "(${_})"; } @filter_ary;
663 # if of a property number or description is requested,
664 # automatically check the matching id too.
665 map { $form->{"l_${_}id"} = "Y" if ($form->{"l_${_}description"} || $form->{"l_${_}number"}); } qw(warehouse bin);
667 # make order, search in $filter and $form
668 my $sort_col = $form->{sort};
669 my $sort_order = $form->{order};
671 $sort_col = $filter{sort} unless $sort_col;
672 # falls $sort_col gar nicht in dem Bericht aufgenommen werden soll,
673 # führt ein entsprechenes order by $sort_col zu einem SQL-Fehler
674 # entsprechend parts_id als default lassen, wenn $sort_col UND l_$sort_col
675 # vorhanden sind (bpsw. l_partnumber = 'Y', für in Bericht aufnehmen).
676 # S.a. Bug 1597 jb 12.5.2011
677 $sort_col = "parts_id" unless ($sort_col && $form->{"l_$sort_col"});
678 $sort_order = $filter{order} unless $sort_order;
679 $sort_col =~ s/ASC|DESC//; # kill stuff left in from previous queries
680 my $orderby = $sort_col;
681 my $sort_spec = "${sort_col} " . ($sort_order ? " DESC" : " ASC");
683 my $where_clause = join " AND ", ("1=1", @filter_ary);
685 my %select_tokens = (
686 "parts_id" => "i.parts_id",
687 "qty" => "SUM(i.qty)",
688 "warehouseid" => "i.warehouse_id",
689 "partnumber" => "p.partnumber",
690 "partdescription" => "p.description",
691 "bindescription" => "b.description",
693 "chargenumber" => "i.chargenumber",
694 "bestbefore" => "i.bestbefore",
696 "chargeid" => "c.id",
697 "warehousedescription" => "w.description",
698 "partunit" => "p.unit",
699 "stock_value" => "p.lastcost / COALESCE(pfac.factor, 1)",
701 my $select_clause = join ', ', map { +/^l_/; "$select_tokens{$'} AS $'" }
702 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
703 qw(l_parts_id l_qty l_partunit) );
705 my $group_clause = join ", ", map { +/^l_/; "$'" }
706 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
707 qw(l_parts_id l_partunit) );
710 "stock_value" => "LEFT JOIN price_factors pfac ON (p.price_factor_id = pfac.id)",
713 my $joins = join ' ', grep { $_ } map { +/^l_/; $join_tokens{"$'"} }
714 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
715 qw(l_parts_id l_qty l_partunit) );
718 qq|SELECT $select_clause
720 LEFT JOIN parts p ON i.parts_id = p.id
721 LEFT JOIN bin b ON i.bin_id = b.id
722 LEFT JOIN warehouse w ON i.warehouse_id = w.id
725 GROUP BY $group_clause
726 ORDER BY $sort_spec|;
728 my $sth = prepare_execute_query($form, $dbh, $query, @filter_vars);
730 my (%non_empty_bins, @all_fields, @contents);
732 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
734 my $qty = $ref->{qty};
736 next unless ($qty != 0);
739 my $part_unit = $all_units->{$ref->{partunit}};
740 next if (!$part_unit || ($part_unit->{base_unit} ne $f_qty_base_unit));
741 $qty *= $part_unit->{factor};
742 next if (('=' eq $f_qty_op) && ($qty != $f_qty));
743 next if (('>=' eq $f_qty_op) && ($qty < $f_qty));
744 next if (('<=' eq $f_qty_op) && ($qty > $f_qty));
747 if ($form->{include_empty_bins}) {
748 $non_empty_bins{$ref->{binid}} = 1;
749 @all_fields = keys %{ $ref } unless (@all_fields);
752 $ref->{stock_value} = ($ref->{stock_value} || 0) * $ref->{qty};
754 push @contents, $ref;
759 if ($form->{include_empty_bins}) {
762 w.id AS warehouseid, w.description AS warehousedescription,
763 b.id AS binid, b.description AS bindescription
765 LEFT JOIN warehouse w ON (b.warehouse_id = w.id)|;
767 @filter_ary = @wh_bin_filter_ary;
768 @filter_vars = @wh_bin_filter_vars;
770 my @non_empty_bin_ids = keys %non_empty_bins;
771 if (@non_empty_bin_ids) {
772 push @filter_ary, qq|NOT b.id IN (| . join(', ', map { '?' } @non_empty_bin_ids) . qq|)|;
773 push @filter_vars, @non_empty_bin_ids;
776 $query .= qq| WHERE | . join(' AND ', map { "($_)" } @filter_ary) if (@filter_ary);
778 $sth = prepare_execute_query($form, $dbh, $query, @filter_vars);
780 while (my $ref = $sth->fetchrow_hashref()) {
781 map { $ref->{$_} ||= "" } @all_fields;
782 push @contents, $ref;
786 if (grep { $orderby eq $_ } qw(bindescription warehousedescription)) {
787 @contents = sort { ($a->{$orderby} cmp $b->{$orderby}) * (($form->{order}) ? 1 : -1) } @contents;
791 $main::lxdebug->leave_sub();
797 $main::lxdebug->enter_sub();
799 my ($self, $qty_op) = @_;
801 if (!$qty_op || ($qty_op eq "dontcare")) {
802 $main::lxdebug->leave_sub();
806 if ($qty_op eq "atleast") {
808 } elsif ($qty_op eq "atmost") {
814 $main::lxdebug->leave_sub();
819 sub retrieve_transfer_types {
820 $main::lxdebug->enter_sub();
823 my $direction = shift;
825 my $myconfig = \%main::myconfig;
826 my $form = $main::form;
828 my $dbh = $form->get_standard_dbh($myconfig);
830 my $types = selectall_hashref_query($form, $dbh, qq|SELECT * FROM transfer_type WHERE direction = ? ORDER BY sortkey|, $direction);
832 $main::lxdebug->leave_sub();
837 sub get_basic_bin_info {
838 $main::lxdebug->enter_sub();
843 Common::check_params(\%params, qw(id));
845 my $myconfig = \%main::myconfig;
846 my $form = $main::form;
848 my $dbh = $params{dbh} || $form->get_standard_dbh();
850 my @ids = 'ARRAY' eq ref $params{id} ? @{ $params{id} } : ($params{id});
853 qq|SELECT b.id AS bin_id, b.description AS bin_description,
854 w.id AS warehouse_id, w.description AS warehouse_description
856 LEFT JOIN warehouse w ON (b.warehouse_id = w.id)
857 WHERE b.id IN (| . join(', ', ('?') x scalar(@ids)) . qq|)|;
859 my $result = selectall_hashref_query($form, $dbh, $query, map { conv_i($_) } @ids);
861 if ('' eq ref $params{id}) {
862 $result = $result->[0] || { };
863 $main::lxdebug->leave_sub();
868 $main::lxdebug->leave_sub();
870 return map { $_->{bin_id} => $_ } @{ $result };
873 # Eingabe: Teilenummer, Lagernummer (warehouse)
874 # Ausgabe: Die maximale Anzahl der Teile in diesem Lager
876 sub get_max_qty_parts {
877 $main::lxdebug->enter_sub();
882 Common::check_params(\%params, qw(parts_id warehouse_id)); #die brauchen wir
884 my $myconfig = \%main::myconfig;
885 my $form = $main::form;
887 my $dbh = $params{dbh} || $form->get_standard_dbh();
889 my $query = qq| SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory where parts_id = ? AND warehouse_id = ? GROUP BY bin_id, chargenumber, bestbefore|;
891 my $sth_QTY = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}, $params{warehouse_id}); #info: aufruf an DBUtils.pm
893 my $max_qty_parts = 0; #Initialisierung mit 0
894 while (my $ref = $sth_QTY->fetchrow_hashref()) { # wir laufen über alle Haltbarkeiten, chargen und Lagerorte (s.a. SQL-Query oben)
895 $max_qty_parts += $ref->{sum};
898 $main::lxdebug->leave_sub();
900 return $max_qty_parts;
904 # Eingabe: Teilenummer, Lagernummer (warehouse)
905 # Ausgabe: Die Beschreibung der Ware bzw. Erzeugnis
907 sub get_part_description {
908 $main::lxdebug->enter_sub();
913 Common::check_params(\%params, qw(parts_id)); #die brauchen wir
915 my $myconfig = \%main::myconfig;
916 my $form = $main::form;
918 my $dbh = $params{dbh} || $form->get_standard_dbh();
920 my $query = qq| SELECT partnumber, description FROM parts where id = ? |;
922 my $sth = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}); #info: aufruf zu DBUtils.pm
924 my $ref = $sth->fetchrow_hashref();
925 my $part_description = $ref->{partnumber} . " " . $ref->{description};
927 $main::lxdebug->leave_sub();
929 return $part_description;
932 # Eingabe: Teilenummer, Lagerplatz_Id (bin_id)
933 # Ausgabe: Die maximale Anzahl der Teile in diesem Lagerplatz
934 # Bzw. Fehler, falls Chargen oder bestbefore
935 # bei eingelagerten Teilen definiert sind.
937 sub get_max_qty_parts_bin {
938 $main::lxdebug->enter_sub();
943 Common::check_params(\%params, qw(parts_id bin_id)); #die brauchen wir
945 my $myconfig = \%main::myconfig;
946 my $form = $main::form;
948 my $dbh = $params{dbh} || $form->get_standard_dbh();
950 my $query = qq| SELECT SUM(qty), chargenumber, bestbefore FROM inventory where parts_id = ?
951 AND bin_id = ? GROUP BY chargenumber, bestbefore|;
953 my $sth_QTY = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}, $params{bin_id}); #info: aufruf an DBUtils.pm
955 my $max_qty_parts = 0; #Initialisierung mit 0
956 # falls derselbe artikel mehrmals eingelagert ist
957 # chargennummer, muss entsprechend händisch agiert werden
960 while (my $ref = $sth_QTY->fetchrow_hashref()) { # wir laufen über alle Haltbarkeiten und Chargen(s.a. SQL-Query oben)
961 $max_qty_parts += $ref->{sum};
963 if ($ref->{chargenumber} || $ref->{bestbefore}){
971 $main::lxdebug->leave_sub();
973 return ($max_qty_parts, $error);
982 SL::WH - Warehouse backend
987 WH->transfer(\%params);
991 Backend for lx-office warehousing functions.
995 =head2 transfer \%PARAMS, [ \%PARAMS, ... ]
997 This is the main function to manipulate warehouse contents. A typical transfer
1003 transfer_type => 'transfer',
1004 src_warehouse_id => 12,
1006 dst_warehouse_id => 25,
1010 It will generate an entry in inventory representing the transfer. Note that
1011 parts_id, qty, and transfer_type are mandatory. Depending on the transfer_type
1012 a destination or a src is mandatory.
1014 transfer accepts more than one transaction parameter, each being a hash ref. If
1015 more than one is supplied, it is guaranteed, that all are processed in the same
1018 Here is a full list of parameters. All "_id" parameters except oe and
1019 orderitems can be called without id with RDB objects as well.
1025 The id of the article transferred. Does not check if the article is a service.
1030 Quantity of the transaction. Mandatory.
1034 Unit of the transaction. Optional.
1038 =item transfer_type_id
1040 The type of transaction. The first version is a string describing the
1041 transaction (the types 'transfer' 'in' 'out' and a few others are present on
1042 every system), the id is the hard id of a transfer_type from the database.
1044 Depending of the direction of the transfer_type, source and/or destination must
1047 One of transfer_type or transfer_type_id is mandatory.
1049 =item src_warehouse_id
1053 Warehouse and bin from which to transfer. Mandatory in transfer and out
1054 directions. Ignored in in directions.
1056 =item dst_warehouse_id
1060 Warehouse and bin to which to transfer. Mandatory in transfer and in
1061 directions. Ignored in out directions.
1065 If given, the transfer will transfer only articles with this chargenumber.
1070 Reference to an orderitem for which this transfer happened. Optional
1074 Reference to an order for which this transfer happened. Optional
1078 An optional comment.
1082 An expiration date. Note that this is not by default used by C<warehouse_report>.