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., 51 Franklin Street, Fifth Floor, Boston,
30 #======================================================================
34 #======================================================================
41 use SL::Util qw(trim);
47 $::lxdebug->enter_sub;
49 my ($self, @args) = @_;
52 $::lxdebug->leave_sub;
56 require SL::DB::TransferType;
58 require SL::DB::Employee;
59 require SL::DB::Inventory;
61 my $employee = SL::DB::Manager::Employee->find_by(login => $::myconfig{login});
62 my ($now) = selectrow_query($::form, $::form->get_standard_dbh, qq|SELECT current_date|);
63 my @directions = (undef, qw(out in transfer));
66 my ($transfer, $field, $class, @find_by) = @_;
68 @find_by = (description => $transfer->{$field}) unless @find_by;
70 if ($transfer->{$field} || $transfer->{"${field}_id"}) {
71 return ref $transfer->{$field} && $transfer->{$field}->isa($class) ? $transfer->{$field}
72 : $transfer->{$field} ? $class->_get_manager_class->find_by(@find_by)
73 : $class->_get_manager_class->find_by(id => $transfer->{"${field}_id"});
80 my $db = SL::DB::Inventory->new->db;
81 $db->with_transaction(sub{
82 while (my $transfer = shift @args) {
83 my ($trans_id) = selectrow_query($::form, $::form->get_standard_dbh, qq|SELECT nextval('id')|);
85 my $part = $objectify->($transfer, 'parts', 'SL::DB::Part');
86 my $unit = $objectify->($transfer, 'unit', 'SL::DB::Unit', name => $transfer->{unit});
87 my $qty = $transfer->{qty};
88 my $src_bin = $objectify->($transfer, 'src_bin', 'SL::DB::Bin');
89 my $dst_bin = $objectify->($transfer, 'dst_bin', 'SL::DB::Bin');
90 my $src_wh = $objectify->($transfer, 'src_warehouse', 'SL::DB::Warehouse');
91 my $dst_wh = $objectify->($transfer, 'dst_warehouse', 'SL::DB::Warehouse');
92 my $project = $objectify->($transfer, 'project', 'SL::DB::Project');
94 $src_wh ||= $src_bin->warehouse if $src_bin;
95 $dst_wh ||= $dst_bin->warehouse if $dst_bin;
97 my $direction = 0; # bit mask
98 $direction |= 1 if $src_bin;
99 $direction |= 2 if $dst_bin;
101 my $transfer_type = $objectify->($transfer, 'transfer_type', 'SL::DB::TransferType', direction => $directions[$direction],
102 description => $transfer->{transfer_type});
106 employee => $employee,
107 trans_type => $transfer_type,
109 trans_id => $trans_id,
110 shippingdate => !$transfer->{shippingdate} || $transfer->{shippingdate} eq 'current_date'
111 ? $now : $transfer->{shippingdate},
112 map { $_ => $transfer->{$_} } qw(chargenumber bestbefore oe_id delivery_order_items_stock_id invoice_id comment),
116 $qty = $unit->convert_to($qty, $part->unit_obj);
119 $params{chargenumber} ||= '';
121 if ($direction & 1) {
122 SL::DB::Inventory->new(
124 warehouse => $src_wh,
130 if ($direction & 2) {
131 SL::DB::Inventory->new(
133 warehouse => $dst_wh->id,
137 # Standardlagerplatz in Stammdaten gleich mitverschieben
138 if (defined($transfer->{change_default_bin})){
139 $part->update_attributes(warehouse_id => $dst_wh->id, bin_id => $dst_bin->id);
143 push @trans_ids, $trans_id;
148 $::form->error("Warehouse transfer error: " . join("\n", (split(/\n/, $db->error))[0..2]));
151 $::lxdebug->leave_sub;
156 sub transfer_assembly {
157 $main::lxdebug->enter_sub();
161 Common::check_params(\%params, qw(assembly_id dst_warehouse_id login qty unit dst_bin_id chargenumber bestbefore comment));
163 # my $maxcreate=WH->check_assembly_max_create(assembly_id =>$params{'assembly_id'}, dbh => $my_dbh);
165 my $myconfig = \%main::myconfig;
166 my $form = $main::form;
167 my $kannNichtFertigen =""; # Falls leer dann erfolgreich
169 SL::DB->client->with_transaction(sub {
170 my $dbh = $params{dbh} || SL::DB->client->dbh;
174 # ... Standard-Check oben Ende. Hier die eigentliche SQL-Abfrage
175 # select parts_id,qty from assembly where id=1064;
176 # Erweiterung für bug 935 am 23.4.09 -
177 # Erzeugnisse können Dienstleistungen enthalten, die ja nicht 'lagerbar' sind.
178 # select parts_id,qty from assembly inner join parts on assembly.parts_id = parts.id
179 # where assembly.id=1066 and inventory_accno_id IS NOT NULL;
181 # Erweiterung für bug 23.4.09 -2 Erzeugnisse in Erzeugnissen können nicht ausgelagert werden,
182 # wenn assembly nicht überprüft wird ...
183 # patch von joachim eingespielt 24.4.2009:
184 # my $query = qq|select parts_id,qty from assembly inner join parts
185 # on assembly.parts_id = parts.id where assembly.id = ? and
186 # (inventory_accno_id IS NOT NULL or parts.assembly = TRUE)|;
188 # Lager in dem die Bestandteile gesucht werden kann entweder das Ziellager sein oder ist per Mandantenkonfig
189 # auf das Standardlager des Bestandteiles schaltbar
191 my $use_default_warehouse = $::instance_conf->get_transfer_default_warehouse_for_assembly;
193 my $query = qq|SELECT assembly.parts_id, assembly.qty, parts.warehouse_id
194 FROM assembly INNER JOIN parts ON assembly.parts_id = parts.id
195 WHERE assembly.id = ? AND parts.part_type != 'service'|;
197 my $sth_part_qty_assembly = prepare_execute_query($form, $dbh, $query, $params{assembly_id});
199 # Hier wird das prepared Statement für die Schleife über alle Lagerplätze vorbereitet
200 my $transferPartSQL = qq|INSERT INTO inventory (parts_id, warehouse_id, bin_id, chargenumber, bestbefore, comment, employee_id, qty,
201 trans_id, trans_type_id, shippingdate)
202 VALUES (?, ?, ?, ?, ?, ?, (SELECT id FROM employee WHERE login = ?), ?, nextval('id'),
203 (SELECT id FROM transfer_type WHERE direction = 'out' AND description = 'used'),
204 (SELECT current_date))|;
205 my $sthTransferPartSQL = prepare_query($form, $dbh, $transferPartSQL);
207 # der return-string für die fehlermeldung inkl. welche waren zum fertigen noch fehlen
209 my $schleife_durchlaufen=0; # Falls die Schleife nicht ausgeführt wird -> Keine Einzelteile definiert. Bessere Idee? jan
210 while (my $hash_ref = $sth_part_qty_assembly->fetchrow_hashref()) { #Schleife für select parts_id,(...) from assembly
211 $schleife_durchlaufen=1; # Erzeugnis definiert
213 my $partsQTY = $hash_ref->{qty} * $params{qty}; # benötigte teile * anzahl erzeugnisse
214 my $currentPart_ID = $hash_ref->{parts_id};
216 my $currentPart_WH_ID = $use_default_warehouse && $hash_ref->{warehouse_id} ? $hash_ref->{warehouse_id} : $params{dst_warehouse_id};
219 # Prüfen ob Erzeugnis-Teile Standardlager haben.
220 if ($use_default_warehouse && ! $hash_ref->{warehouse_id}) {
221 # Prüfen ob in Mandantenkonfiguration ein Standardlager aktiviert isti.
222 if ($::instance_conf->get_transfer_default_ignore_onhand) {
223 $currentPart_WH_ID = $::instance_conf->get_warehouse_id_ignore_onhand;
226 $kannNichtFertigen .= "Kein Standardlager: " .
227 " Die Ware " . $self->get_part_description(parts_id => $currentPart_ID) .
228 " hat kein Standardlager definiert " .
229 ", um das Erzeugnis herzustellen. <br>";
233 my $warehouse_info = $self->get_basic_warehouse_info('id'=> $currentPart_WH_ID);
234 my $warehouse_desc = $warehouse_info->{"warehouse_description"};
236 # Fertigen ohne Prüfung nach Bestand
238 my $temppart_bin_id = $::instance_conf->get_bin_id_ignore_onhand;
239 my $temppart_chargenumber = "";
240 my $temppart_bestbefore = localtime();
241 my $temppart_qty = $partsQTY * -1;
243 do_statement($form, $sthTransferPartSQL, $transferPartSQL, $currentPart_ID, $currentPart_WH_ID,
244 $temppart_bin_id, $temppart_chargenumber, $temppart_bestbefore, 'Verbraucht für ' .
245 $self->get_part_description(parts_id => $params{assembly_id}), $params{login}, $temppart_qty);
248 # Überprüfen, ob diese Anzahl gefertigt werden kann
249 my $max_parts = $self->get_max_qty_parts(parts_id => $currentPart_ID, # $self->method() == this.method()
250 warehouse_id => $currentPart_WH_ID);
252 if ($partsQTY > $max_parts){
253 # Gibt es hier ein Problem mit nicht "escapten" Zeichen?
254 # 25.4.09 Antwort: Ja. Aber erst wenn im Frontend die locales-Funktion aufgerufen wird
256 $kannNichtFertigen .= "Zum Fertigen fehlen: " . abs($partsQTY - $max_parts) .
257 " Einheiten der Ware: " . $self->get_part_description(parts_id => $currentPart_ID) .
258 " im Lager: " . $warehouse_desc .
259 ", um das Erzeugnis herzustellen. <br>"; # Konnte die Menge nicht mit der aktuellen Anzahl der Waren fertigen
260 next; # die weiteren Überprüfungen sind unnötig, daher das nächste elemente prüfen (genaue Ausgabe, was noch fehlt)
263 # Eine kurze Vorabfrage, um den Lagerplatz, Chargennummer und die Mindesthaltbarkeit zu bestimmen
264 # Offen: Die Summe über alle Lagerplätze wird noch nicht gebildet
265 # Gelöst: Wir haben vorher schon die Abfrage durchgeführt, ob wir fertigen können.
266 # Noch besser gelöst: Wir laufen durch alle benötigten Waren zum Fertigen und geben eine Rückmeldung an den Benutzer was noch fehlt
267 # und lösen den Rest dann so wie bei xplace im Barcode-Programm
268 # S.a. Kommentar im bin/mozilla-Code mb übernimmt und macht das in ordentlich
270 my $tempquery = qq|SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory
271 WHERE warehouse_id = ? AND parts_id = ? GROUP BY bin_id, chargenumber, bestbefore having SUM(qty)>0|;
272 my $tempsth = prepare_execute_query($form, $dbh, $tempquery, $currentPart_WH_ID, $currentPart_ID);
274 # Alle Werte zu dem einzelnen Artikel, die wir später auslagern
275 my $tmpPartsQTY = $partsQTY;
277 while (my $temphash_ref = $tempsth->fetchrow_hashref()) {
278 my $temppart_bin_id = $temphash_ref->{bin_id}; # kann man hier den quelllagerplatz beim verbauen angeben?
279 my $temppart_chargenumber = $temphash_ref->{chargenumber};
280 my $temppart_bestbefore = conv_date($temphash_ref->{bestbefore});
281 my $temppart_qty = $temphash_ref->{sum};
283 if ($tmpPartsQTY > $temppart_qty) { # wir haben noch mehr waren zum wegbuchen.
284 # Wir buchen den kompletten Lagerplatzbestand und zählen die Hilfsvariable runter
285 $tmpPartsQTY = $tmpPartsQTY - $temppart_qty;
286 $temppart_qty = $temppart_qty * -1; # TODO beim analyiseren des sql-trace, war dieser wert positiv,
287 # wenn * -1 als berechnung in der parameter-übergabe angegeben wird.
288 # Dieser Wert IST und BLEIBT positiv!! Hilfe.
289 # Liegt das daran, dass dieser Wert aus einem SQL-Statement stammt?
290 do_statement($form, $sthTransferPartSQL, $transferPartSQL, $currentPart_ID, $currentPart_WH_ID,
291 $temppart_bin_id, $temppart_chargenumber, $temppart_bestbefore, 'Verbraucht für ' .
292 $self->get_part_description(parts_id => $params{assembly_id}), $params{login}, $temppart_qty);
294 # hier ist noch ein fehler am besten mit definierten erzeugnissen debuggen 02/2009 jb
295 # idee: ausbuch algorithmus mit rekursion lösen und an- und abschaltbar machen
296 # das problem könnte sein, dass strict nicht an war und sth global eine andere zuweisung bekam
297 # auf jeden fall war der internal-server-error nach aktivierung von strict und warnings plus ein paar my-definitionen weg
298 } else { # okay, wir haben weniger oder gleich Waren die wir wegbuchen müssen, wir können also aufhören
300 do_statement($form, $sthTransferPartSQL, $transferPartSQL, $currentPart_ID, $currentPart_WH_ID,
301 $temppart_bin_id, $temppart_chargenumber, $temppart_bestbefore, 'Verbraucht für ' .
302 $self->get_part_description(parts_id => $params{assembly_id}), $params{login}, $tmpPartsQTY);
303 last; # beendet die schleife (springt zum letzten element)
305 } # ende while SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory WHERE warehouse_id
306 } #ende while select parts_id,qty from assembly where id = ?
308 if ($schleife_durchlaufen==0){ # falls die schleife nicht durchlaufen wurde, wurden auch
309 # keine einzelteile definiert
310 $kannNichtFertigen ="Für dieses Erzeugnis sind keine Einzelteile definiert.
311 Dementsprechend kann auch nichts hergestellt werden";
313 # gibt die Fehlermeldung zurück. A.) Keine Teile definiert
314 # B.) Artikel und Anzahl der fehlenden Teile/Dienstleistungen
315 die "<br><br>" . $kannNichtFertigen if ($kannNichtFertigen);
317 # soweit alles gut. Jetzt noch die wirkliche Lagerbewegung für das Erzeugnis ausführen ...
318 my $transferAssemblySQL = qq|INSERT INTO inventory (parts_id, warehouse_id, bin_id, chargenumber, bestbefore,
319 comment, employee_id, qty, trans_id, trans_type_id, shippingdate)
320 VALUES (?, ?, ?, ?, ?, ?, (SELECT id FROM employee WHERE login = ?), ?, nextval('id'),
321 (SELECT id FROM transfer_type WHERE direction = 'in' AND description = 'assembled'),
322 (select current_date))|;
323 my $sthTransferAssemblySQL = prepare_query($form, $dbh, $transferAssemblySQL);
324 do_statement($form, $sthTransferAssemblySQL, $transferAssemblySQL, $params{assembly_id}, $params{dst_warehouse_id},
325 $params{dst_bin_id}, $params{chargenumber}, conv_date($params{bestbefore}), $params{comment}, $params{login}, $params{qty});
327 }) or do { return $kannNichtFertigen };
329 $main::lxdebug->leave_sub();
330 return 1; # Alles erfolgreich
333 sub get_warehouse_journal {
334 $main::lxdebug->enter_sub();
339 my $myconfig = \%main::myconfig;
340 my $form = $main::form;
342 my $all_units = AM->retrieve_units($myconfig, $form);
344 # connect to database
345 my $dbh = $form->get_standard_dbh($myconfig);
348 my (@filter_ary, @filter_vars, $joins, %select_tokens, %select);
350 if ($filter{warehouse_id}) {
351 push @filter_ary, "w1.id = ? OR w2.id = ?";
352 push @filter_vars, $filter{warehouse_id}, $filter{warehouse_id};
355 if ($filter{bin_id}) {
356 push @filter_ary, "b1.id = ? OR b2.id = ?";
357 push @filter_vars, $filter{bin_id}, $filter{bin_id};
360 if ($filter{partnumber}) {
361 push @filter_ary, "p.partnumber ILIKE ?";
362 push @filter_vars, like($filter{partnumber});
365 if ($filter{description}) {
366 push @filter_ary, "(p.description ILIKE ?)";
367 push @filter_vars, like($filter{description});
370 if ($filter{classification_id}) {
371 push @filter_ary, "p.classification_id = ?";
372 push @filter_vars, $filter{classification_id};
375 if ($filter{chargenumber}) {
376 push @filter_ary, "i1.chargenumber ILIKE ?";
377 push @filter_vars, like($filter{chargenumber});
380 if (trim($form->{bestbefore})) {
381 push @filter_ary, "?::DATE = i1.bestbefore::DATE";
382 push @filter_vars, trim($form->{bestbefore});
385 if (trim($form->{fromdate})) {
386 push @filter_ary, "? <= i1.shippingdate";
387 push @filter_vars, trim($form->{fromdate});
390 if (trim($form->{todate})) {
391 push @filter_ary, "? >= i1.shippingdate";
392 push @filter_vars, trim($form->{todate});
395 if ($form->{l_employee}) {
399 # prepare qty comparison for later filtering
400 my ($f_qty_op, $f_qty, $f_qty_base_unit);
401 if ($filter{qty_op} && defined($filter{qty}) && $filter{qty_unit} && $all_units->{$filter{qty_unit}}) {
402 $f_qty_op = $filter{qty_op};
403 $f_qty = $filter{qty} * $all_units->{$filter{qty_unit}}->{factor};
404 $f_qty_base_unit = $all_units->{$filter{qty_unit}}->{base_unit};
407 map { $_ = "(${_})"; } @filter_ary;
409 # if of a property number or description is requested,
410 # automatically check the matching id too.
411 map { $form->{"l_${_}id"} = "Y" if ($form->{"l_${_}description"} || $form->{"l_${_}number"}); } qw(warehouse bin);
413 # customize shown entry for not available fields.
414 $filter{na} = '-' unless $filter{na};
416 # make order, search in $filter and $form
417 my $sort_col = $form->{sort};
418 my $sort_order = $form->{order};
420 $sort_col = $filter{sort} unless $sort_col;
421 $sort_col = 'shippingdate' if $sort_col eq 'date';
422 $sort_order = ($sort_col = 'shippingdate') unless $sort_col;
425 'shippingdate' => ['shippingdate', 'r_itime', 'r_parts_id'],
426 'bin_to' => ['bin_to', 'r_itime', 'r_parts_id'],
427 'bin_from' => ['bin_from', 'r_itime', 'r_parts_id'],
428 'warehouse_to' => ['warehouse_to, r_itime, r_parts_id'],
429 'warehouse_from' => ['warehouse_from, r_itime, r_parts_id'],
430 'partnumber' => ['partnumber'],
431 'partdescription'=> ['partdescription'],
432 'partunit' => ['partunit, r_itime, r_parts_id'],
433 'qty' => ['qty, r_itime, r_parts_id'],
434 'oe_id' => ['oe_id'],
435 'comment' => ['comment'],
436 'trans_type' => ['trans_type'],
437 'employee' => ['employee'],
438 'projectnumber' => ['projectnumber'],
439 'chargenumber' => ['chargenumber'],
442 $sort_order = $filter{order} unless $sort_order;
443 my $ASC = ($sort_order ? " DESC" : " ASC");
444 my $sort_spec = join("$ASC , ", @{$orderspecs{$sort_col}}). " $ASC";
446 my $where_clause = @filter_ary ? join(" AND ", @filter_ary) . " AND " : '';
448 $select_tokens{'trans'} = {
449 "parts_id" => "i1.parts_id",
450 "qty" => "ABS(SUM(i1.qty))",
451 "partnumber" => "p.partnumber",
452 "partdescription" => "p.description",
453 "classification_id" => "p.classification_id",
454 "part_type" => "p.part_type",
455 "bindescription" => "b.description",
456 "chargenumber" => "i1.chargenumber",
457 "bestbefore" => "i1.bestbefore",
458 "warehousedescription" => "w.description",
459 "partunit" => "p.unit",
460 "bin_from" => "b1.description",
461 "bin_to" => "b2.description",
462 "warehouse_from" => "w1.description",
463 "warehouse_to" => "w2.description",
464 "comment" => "i1.comment",
465 "trans_type" => "tt.description",
466 "trans_id" => "i1.trans_id",
467 "oe_id" => "COALESCE(i1.oe_id, i2.oe_id)",
468 "invoice_id" => "COALESCE(i1.invoice_id, i2.invoice_id)",
469 "date" => "i1.shippingdate",
470 "itime" => "i1.itime",
471 "shippingdate" => "i1.shippingdate",
472 "employee" => "e.name",
473 "projectnumber" => "COALESCE(pr.projectnumber, '$filter{na}')",
476 $select_tokens{'out'} = {
477 "bin_to" => "'$filter{na}'",
478 "warehouse_to" => "'$filter{na}'",
481 $select_tokens{'in'} = {
482 "bin_from" => "'$filter{na}'",
483 "warehouse_from" => "'$filter{na}'",
486 $form->{l_classification_id} = 'Y';
487 $form->{l_part_type} = 'Y';
488 $form->{l_itime} = 'Y';
489 $form->{l_invoice_id} = $form->{l_oe_id} if $form->{l_oe_id};
491 # build the select clauses.
492 # take all the requested ones from the first hash and overwrite them from the out/in hashes if present.
493 for my $i ('trans', 'out', 'in') {
494 $select{$i} = join ', ', map { +/^l_/; ($select_tokens{$i}{"$'"} || $select_tokens{'trans'}{"$'"}) . " AS r_$'" }
495 ( grep( { !/qty$/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form), qw(l_parts_id l_qty l_partunit l_shippingdate) );
498 my $group_clause = join ", ", map { +/^l_/; "r_$'" }
499 ( grep( { !/qty$/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form), qw(l_parts_id l_partunit l_shippingdate l_itime) );
501 $where_clause = defined($where_clause) ? $where_clause : '';
504 qq|SELECT * FROM (SELECT DISTINCT $select{trans}
506 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
507 LEFT JOIN parts p ON i1.parts_id = p.id
508 LEFT JOIN bin b1 ON i1.bin_id = b1.id
509 LEFT JOIN bin b2 ON i2.bin_id = b2.id
510 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
511 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
512 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
513 LEFT JOIN project pr ON i1.project_id = pr.id
514 LEFT JOIN employee e ON i1.employee_id = e.id
515 WHERE $where_clause i2.qty = -i1.qty AND i2.qty > 0 AND
516 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 2 )
517 GROUP BY $group_clause
521 SELECT DISTINCT $select{out}
523 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
524 LEFT JOIN parts p ON i1.parts_id = p.id
525 LEFT JOIN bin b1 ON i1.bin_id = b1.id
526 LEFT JOIN bin b2 ON i2.bin_id = b2.id
527 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
528 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
529 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
530 LEFT JOIN project pr ON i1.project_id = pr.id
531 LEFT JOIN employee e ON i1.employee_id = e.id
532 WHERE $where_clause i1.qty < 0 AND
533 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 1 )
534 GROUP BY $group_clause
538 SELECT DISTINCT $select{in}
540 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
541 LEFT JOIN parts p ON i1.parts_id = p.id
542 LEFT JOIN bin b1 ON i1.bin_id = b1.id
543 LEFT JOIN bin b2 ON i2.bin_id = b2.id
544 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
545 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
546 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
547 LEFT JOIN project pr ON i1.project_id = pr.id
548 LEFT JOIN employee e ON i1.employee_id = e.id
549 WHERE $where_clause i1.qty > 0 AND
550 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 1 )
551 GROUP BY $group_clause
552 ORDER BY r_${sort_spec}) AS lines WHERE r_qty>0|;
554 my @all_vars = (@filter_vars,@filter_vars,@filter_vars);
556 if ($filter{limit}) {
557 $query .= " LIMIT ?";
558 push @all_vars,$filter{limit};
560 if ($filter{offset}) {
561 $query .= " OFFSET ?";
562 push @all_vars, $filter{offset};
565 my $sth = prepare_execute_query($form, $dbh, $query, @all_vars);
567 my ($h_oe_id, $q_oe_id);
568 if ($form->{l_oe_id}) {
570 SELECT dord.id AS id, dord.donumber AS number,
572 WHEN dord.customer_id IS NULL THEN 'purchase_delivery_order'
573 ELSE 'sales_delivery_order'
575 FROM delivery_orders dord
580 SELECT ar.id AS id, ar.invnumber AS number, 'sales_invoice' AS type
582 WHERE ar.id = (SELECT trans_id FROM invoice WHERE id = ?)
586 SELECT ap.id AS id, ap.invnumber AS number, 'purchase_invoice' AS type
588 WHERE ap.id = (SELECT trans_id FROM invoice WHERE id = ?)
590 $h_oe_id = prepare_query($form, $dbh, $q_oe_id);
594 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
595 map { /^r_/; $ref->{"$'"} = $ref->{$_} } keys %$ref;
596 my $qty = $ref->{"qty"} * 1;
598 next unless ($qty > 0);
601 my $part_unit = $all_units->{$ref->{"partunit"}};
602 next unless ($part_unit && ($part_unit->{"base_unit"} eq $f_qty_base_unit));
603 $qty *= $part_unit->{"factor"};
604 next if (('=' eq $f_qty_op) && ($qty != $f_qty));
605 next if (('>=' eq $f_qty_op) && ($qty < $f_qty));
606 next if (('<=' eq $f_qty_op) && ($qty > $f_qty));
609 if ($h_oe_id && ($ref->{oe_id} || $ref->{invoice_id})) {
610 do_statement($form, $h_oe_id, $q_oe_id, $ref->{oe_id}, ($ref->{invoice_id}) x 2);
611 $ref->{oe_id_info} = $h_oe_id->fetchrow_hashref() || {};
614 push @contents, $ref;
618 $h_oe_id->finish() if $h_oe_id;
620 $main::lxdebug->leave_sub();
626 # This sub is the primary function to retrieve information about items in warehouses.
627 # $filter is a hashref and supports the following keys:
628 # - warehouse_id - will return matches with this warehouse_id only
629 # - partnumber - will return only matches where the given string is a substring of the partnumber
630 # - partsid - will return matches with this parts_id only
631 # - classification_id - will return matches with this parts with this classification only
632 # - description - will return only matches where the given string is a substring of the description
633 # - chargenumber - will return only matches where the given string is a substring of the chargenumber
634 # - bestbefore - will return only matches with this bestbefore date
635 # - ean - will return only matches where the given string is a substring of the ean as stored in the table parts (article)
636 # - charge_ids - must be an arrayref. will return contents with these ids only
637 # - expires_in - will only return matches that expire within the given number of days
638 # will also add a column named 'has_expired' containing if the match has already expired or not
639 # - hazardous - will return matches with the flag hazardous only
640 # - oil - will return matches with the flag oil only
641 # - qty, qty_op - quantity filter (more info to come)
642 # - sort, order_by - sorting (more to come)
643 # - reservation - will provide an extra column containing the amount reserved of this match
644 # note: reservation flag turns off warehouse_* or bin_* information. both together don't make sense, since reserved info is stored separately
646 sub get_warehouse_report {
647 $main::lxdebug->enter_sub();
652 my $myconfig = \%main::myconfig;
653 my $form = $main::form;
655 my $all_units = AM->retrieve_units($myconfig, $form);
657 # connect to database
658 my $dbh = $form->get_standard_dbh($myconfig);
661 my (@filter_ary, @filter_vars, @wh_bin_filter_ary, @wh_bin_filter_vars);
663 delete $form->{include_empty_bins} unless ($form->{l_warehousedescription} || $form->{l_bindescription});
665 if ($filter{warehouse_id}) {
666 push @wh_bin_filter_ary, "w.id = ?";
667 push @wh_bin_filter_vars, $filter{warehouse_id};
670 if ($filter{bin_id}) {
671 push @wh_bin_filter_ary, "b.id = ?";
672 push @wh_bin_filter_vars, $filter{bin_id};
675 push @filter_ary, @wh_bin_filter_ary;
676 push @filter_vars, @wh_bin_filter_vars;
678 if ($filter{partnumber}) {
679 push @filter_ary, "p.partnumber ILIKE ?";
680 push @filter_vars, like($filter{partnumber});
683 if ($filter{classification_id}) {
684 push @filter_ary, "p.classification_id = ?";
685 push @filter_vars, $filter{classification_id};
688 if ($filter{description}) {
689 push @filter_ary, "p.description ILIKE ?";
690 push @filter_vars, like($filter{description});
693 if ($filter{partsid}) {
694 push @filter_ary, "p.id = ?";
695 push @filter_vars, $filter{partsid};
698 if ($filter{chargenumber}) {
699 push @filter_ary, "i.chargenumber ILIKE ?";
700 push @filter_vars, like($filter{chargenumber});
703 if (trim($form->{bestbefore})) {
704 push @filter_ary, "?::DATE = i.bestbefore::DATE";
705 push @filter_vars, trim($form->{bestbefore});
708 if ($filter{classification_id}) {
709 push @filter_ary, "p.classification_id = ?";
710 push @filter_vars, $filter{classification_id};
714 push @filter_ary, "p.ean ILIKE ?";
715 push @filter_vars, like($filter{ean});
718 if (trim($filter{date})) {
719 push @filter_ary, "i.shippingdate <= ?";
720 push @filter_vars, trim($filter{date});
722 if (!$filter{include_invalid_warehouses}){
723 push @filter_ary, "NOT (w.invalid)";
726 # prepare qty comparison for later filtering
727 my ($f_qty_op, $f_qty, $f_qty_base_unit);
729 if ($filter{qty_op} && defined $filter{qty} && $filter{qty_unit} && $all_units->{$filter{qty_unit}}) {
730 $f_qty_op = $filter{qty_op};
731 $f_qty = $filter{qty} * $all_units->{$filter{qty_unit}}->{factor};
732 $f_qty_base_unit = $all_units->{$filter{qty_unit}}->{base_unit};
735 map { $_ = "(${_})"; } @filter_ary;
737 # if of a property number or description is requested,
738 # automatically check the matching id too.
739 map { $form->{"l_${_}id"} = "Y" if ($form->{"l_${_}description"} || $form->{"l_${_}number"}); } qw(warehouse bin);
741 # make order, search in $filter and $form
742 my $sort_col = $form->{sort};
743 my $sort_order = $form->{order};
745 $sort_col = $filter{sort} unless $sort_col;
746 # falls $sort_col gar nicht in dem Bericht aufgenommen werden soll,
747 # führt ein entsprechenes order by $sort_col zu einem SQL-Fehler
748 # entsprechend parts_id als default lassen, wenn $sort_col UND l_$sort_col
749 # vorhanden sind (bpsw. l_partnumber = 'Y', für in Bericht aufnehmen).
750 # S.a. Bug 1597 jb 12.5.2011
751 $sort_col = "parts_id" unless ($sort_col && $form->{"l_$sort_col"});
752 $sort_order = $filter{order} unless $sort_order;
753 $sort_col =~ s/ASC|DESC//; # kill stuff left in from previous queries
754 my $orderby = $sort_col;
755 my $sort_spec = "${sort_col} " . ($sort_order ? " DESC" : " ASC");
757 my $where_clause = join " AND ", ("1=1", @filter_ary);
759 my %select_tokens = (
760 "parts_id" => "i.parts_id",
761 "qty" => "SUM(i.qty)",
762 "warehouseid" => "i.warehouse_id",
763 "partnumber" => "p.partnumber",
764 "partdescription" => "p.description",
765 "classification_id" => "p.classification_id",
766 "part_type" => "p.part_type",
767 "bindescription" => "b.description",
769 "chargenumber" => "i.chargenumber",
770 "bestbefore" => "i.bestbefore",
772 "chargeid" => "c.id",
773 "warehousedescription" => "w.description",
774 "partunit" => "p.unit",
775 "stock_value" => "p.lastcost / COALESCE(pfac.factor, 1)",
776 "purchase_price" => "p.lastcost",
778 $form->{l_classification_id} = 'Y';
779 $form->{l_part_type} = 'Y';
781 my $select_clause = join ', ', map { +/^l_/; "$select_tokens{$'} AS $'" }
782 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
783 qw(l_parts_id l_qty l_partunit) );
785 my $group_clause = join ", ", map { +/^l_/; "$'" }
786 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
787 qw(l_parts_id l_partunit) );
790 "stock_value" => "LEFT JOIN price_factors pfac ON (p.price_factor_id = pfac.id)",
793 my $joins = join ' ', grep { $_ } map { +/^l_/; $join_tokens{"$'"} }
794 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
795 qw(l_parts_id l_qty l_partunit) );
798 qq|SELECT * FROM ( SELECT $select_clause
800 LEFT JOIN parts p ON i.parts_id = p.id
801 LEFT JOIN bin b ON i.bin_id = b.id
802 LEFT JOIN warehouse w ON i.warehouse_id = w.id
805 GROUP BY $group_clause
806 ORDER BY $sort_spec ) AS lines WHERE qty<>0|;
808 if ($filter{limit}) {
809 $query .= " LIMIT ?";
810 push @filter_vars,$filter{limit};
812 if ($filter{offset}) {
813 $query .= " OFFSET ?";
814 push @filter_vars, $filter{offset};
816 my $sth = prepare_execute_query($form, $dbh, $query, @filter_vars );
818 my (%non_empty_bins, @all_fields, @contents);
820 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
822 my $qty = $ref->{qty};
824 next unless ($qty != 0);
827 my $part_unit = $all_units->{$ref->{partunit}};
828 next if (!$part_unit || ($part_unit->{base_unit} ne $f_qty_base_unit));
829 $qty *= $part_unit->{factor};
830 next if (('=' eq $f_qty_op) && ($qty != $f_qty));
831 next if (('>=' eq $f_qty_op) && ($qty < $f_qty));
832 next if (('<=' eq $f_qty_op) && ($qty > $f_qty));
835 if ($form->{include_empty_bins}) {
836 $non_empty_bins{$ref->{binid}} = 1;
837 @all_fields = keys %{ $ref } unless (@all_fields);
840 $ref->{stock_value} = ($ref->{stock_value} || 0) * $ref->{qty};
842 push @contents, $ref;
847 if ($form->{include_empty_bins}) {
850 w.id AS warehouseid, w.description AS warehousedescription,
851 b.id AS binid, b.description AS bindescription
853 LEFT JOIN warehouse w ON (b.warehouse_id = w.id)|;
855 @filter_ary = @wh_bin_filter_ary;
856 @filter_vars = @wh_bin_filter_vars;
858 my @non_empty_bin_ids = keys %non_empty_bins;
859 if (@non_empty_bin_ids) {
860 push @filter_ary, qq|NOT b.id IN (| . join(', ', map { '?' } @non_empty_bin_ids) . qq|)|;
861 push @filter_vars, @non_empty_bin_ids;
864 $query .= qq| WHERE | . join(' AND ', map { "($_)" } @filter_ary) if (@filter_ary);
866 $sth = prepare_execute_query($form, $dbh, $query, @filter_vars);
868 while (my $ref = $sth->fetchrow_hashref()) {
869 map { $ref->{$_} ||= "" } @all_fields;
870 push @contents, $ref;
874 if (grep { $orderby eq $_ } qw(bindescription warehousedescription)) {
875 @contents = sort { ($a->{$orderby} cmp $b->{$orderby}) * (($form->{order}) ? 1 : -1) } @contents;
879 $main::lxdebug->leave_sub();
885 $main::lxdebug->enter_sub();
887 my ($self, $qty_op) = @_;
889 if (!$qty_op || ($qty_op eq "dontcare")) {
890 $main::lxdebug->leave_sub();
894 if ($qty_op eq "atleast") {
896 } elsif ($qty_op eq "atmost") {
902 $main::lxdebug->leave_sub();
907 sub retrieve_transfer_types {
908 $main::lxdebug->enter_sub();
911 my $direction = shift;
913 my $myconfig = \%main::myconfig;
914 my $form = $main::form;
916 my $dbh = $form->get_standard_dbh($myconfig);
918 my $types = selectall_hashref_query($form, $dbh, qq|SELECT * FROM transfer_type WHERE direction = ? ORDER BY sortkey|, $direction);
920 $main::lxdebug->leave_sub();
925 sub get_basic_bin_info {
926 $main::lxdebug->enter_sub();
931 Common::check_params(\%params, qw(id));
933 my $myconfig = \%main::myconfig;
934 my $form = $main::form;
936 my $dbh = $params{dbh} || $form->get_standard_dbh();
938 my @ids = 'ARRAY' eq ref $params{id} ? @{ $params{id} } : ($params{id});
941 qq|SELECT b.id AS bin_id, b.description AS bin_description,
942 w.id AS warehouse_id, w.description AS warehouse_description
944 LEFT JOIN warehouse w ON (b.warehouse_id = w.id)
945 WHERE b.id IN (| . join(', ', ('?') x scalar(@ids)) . qq|)|;
947 my $result = selectall_hashref_query($form, $dbh, $query, map { conv_i($_) } @ids);
949 if ('' eq ref $params{id}) {
950 $result = $result->[0] || { };
951 $main::lxdebug->leave_sub();
956 $main::lxdebug->leave_sub();
958 return map { $_->{bin_id} => $_ } @{ $result };
961 sub get_basic_warehouse_info {
962 $main::lxdebug->enter_sub();
967 Common::check_params(\%params, qw(id));
969 my $myconfig = \%main::myconfig;
970 my $form = $main::form;
972 my $dbh = $params{dbh} || $form->get_standard_dbh();
974 my @ids = 'ARRAY' eq ref $params{id} ? @{ $params{id} } : ($params{id});
977 qq|SELECT w.id AS warehouse_id, w.description AS warehouse_description
979 WHERE w.id IN (| . join(', ', ('?') x scalar(@ids)) . qq|)|;
981 my $result = selectall_hashref_query($form, $dbh, $query, map { conv_i($_) } @ids);
983 if ('' eq ref $params{id}) {
984 $result = $result->[0] || { };
985 $main::lxdebug->leave_sub();
990 $main::lxdebug->leave_sub();
992 return map { $_->{warehouse_id} => $_ } @{ $result };
995 # Eingabe: Teilenummer, Lagernummer (warehouse)
996 # Ausgabe: Die maximale Anzahl der Teile in diesem Lager
998 sub get_max_qty_parts {
999 $main::lxdebug->enter_sub();
1004 Common::check_params(\%params, qw(parts_id warehouse_id)); #die brauchen wir
1006 my $myconfig = \%main::myconfig;
1007 my $form = $main::form;
1009 my $dbh = $params{dbh} || $form->get_standard_dbh();
1011 my $query = qq| SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory where parts_id = ? AND warehouse_id = ? GROUP BY bin_id, chargenumber, bestbefore|;
1012 my $sth_QTY = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}, $params{warehouse_id}); #info: aufruf an DBUtils.pm
1015 my $max_qty_parts = 0; #Initialisierung mit 0
1016 while (my $ref = $sth_QTY->fetchrow_hashref()) { # wir laufen über alle Haltbarkeiten, chargen und Lagerorte (s.a. SQL-Query oben)
1017 $max_qty_parts += $ref->{sum};
1020 $main::lxdebug->leave_sub();
1022 return $max_qty_parts;
1026 # Eingabe: Teilenummer, Lagernummer (warehouse)
1027 # Ausgabe: Die Beschreibung der Ware bzw. Erzeugnis
1029 sub get_part_description {
1030 $main::lxdebug->enter_sub();
1035 Common::check_params(\%params, qw(parts_id)); #die brauchen wir
1037 my $myconfig = \%main::myconfig;
1038 my $form = $main::form;
1040 my $dbh = $params{dbh} || $form->get_standard_dbh();
1042 my $query = qq| SELECT partnumber, description FROM parts where id = ? |;
1044 my $sth = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}); #info: aufruf zu DBUtils.pm
1046 my $ref = $sth->fetchrow_hashref();
1047 my $part_description = $ref->{partnumber} . " " . $ref->{description};
1049 $main::lxdebug->leave_sub();
1051 return $part_description;
1054 # Eingabe: Teilenummer, Lagerplatz_Id (bin_id)
1055 # Ausgabe: Die maximale Anzahl der Teile in diesem Lagerplatz
1056 # Bzw. Fehler, falls Chargen oder bestbefore
1057 # bei eingelagerten Teilen definiert sind.
1059 sub get_max_qty_parts_bin {
1060 $main::lxdebug->enter_sub();
1065 Common::check_params(\%params, qw(parts_id bin_id)); #die brauchen wir
1067 my $myconfig = \%main::myconfig;
1068 my $form = $main::form;
1070 my $dbh = $params{dbh} || $form->get_standard_dbh();
1072 my $query = qq| SELECT SUM(qty), chargenumber, bestbefore FROM inventory where parts_id = ?
1073 AND bin_id = ? GROUP BY chargenumber, bestbefore|;
1075 my $sth_QTY = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}, $params{bin_id}); #info: aufruf an DBUtils.pm
1077 my $max_qty_parts = 0; #Initialisierung mit 0
1078 # falls derselbe artikel mehrmals eingelagert ist
1079 # chargennummer, muss entsprechend händisch agiert werden
1082 while (my $ref = $sth_QTY->fetchrow_hashref()) { # wir laufen über alle Haltbarkeiten und Chargen(s.a. SQL-Query oben)
1083 $max_qty_parts += $ref->{sum};
1085 if (($ref->{chargenumber} || $ref->{bestbefore}) && $ref->{sum} != 0){
1089 $main::lxdebug->leave_sub();
1091 return ($max_qty_parts, $error);
1100 SL::WH - Warehouse backend
1105 WH->transfer(\%params);
1109 Backend for kivitendo warehousing functions.
1113 =head2 transfer \%PARAMS, [ \%PARAMS, ... ]
1115 This is the main function to manipulate warehouse contents. A typical transfer
1116 is called like this:
1121 transfer_type => 'transfer',
1122 src_warehouse_id => 12,
1124 dst_warehouse_id => 25,
1128 It will generate an entry in inventory representing the transfer. Note that
1129 parts_id, qty, and transfer_type are mandatory. Depending on the transfer_type
1130 a destination or a src is mandatory.
1132 transfer accepts more than one transaction parameter, each being a hash ref. If
1133 more than one is supplied, it is guaranteed, that all are processed in the same
1136 Here is a full list of parameters. All "_id" parameters except oe and
1137 orderitems can be called without id with RDB objects as well.
1143 The id of the article transferred. Does not check if the article is a service.
1148 Quantity of the transaction. Mandatory.
1152 Unit of the transaction. Optional.
1156 =item transfer_type_id
1158 The type of transaction. The first version is a string describing the
1159 transaction (the types 'transfer' 'in' 'out' and a few others are present on
1160 every system), the id is the hard id of a transfer_type from the database.
1162 Depending of the direction of the transfer_type, source and/or destination must
1165 One of transfer_type or transfer_type_id is mandatory.
1167 =item src_warehouse_id
1171 Warehouse and bin from which to transfer. Mandatory in transfer and out
1172 directions. Ignored in in directions.
1174 =item dst_warehouse_id
1178 Warehouse and bin to which to transfer. Mandatory in transfer and in
1179 directions. Ignored in out directions.
1183 If given, the transfer will transfer only articles with this chargenumber.
1188 Reference to an orderitem for which this transfer happened. Optional
1192 Reference to an order for which this transfer happened. Optional
1196 An optional comment.
1200 An expiration date. Note that this is not by default used by C<warehouse_report>.
1204 =head2 create_assembly \%PARAMS, [ \%PARAMS, ... ]
1206 Creates an assembly if all defined items are available.
1208 Assembly item(s) will be stocked out and the assembly will be stocked in,
1209 taking into account the qty and units which can be defined for each
1210 assembly item separately.
1212 The calling params originate from C<transfer> but only parts_id with the
1213 attribute assembly are processed.
1215 The typical params would be:
1218 'login' => $::myconfig{login},
1219 'dst_warehouse_id' => $form->{warehouse_id},
1220 'dst_bin_id' => $form->{bin_id},
1221 'chargenumber' => $form->{chargenumber},
1222 'bestbefore' => $form->{bestbefore},
1223 'assembly_id' => $form->{parts_id},
1224 'qty' => $form->{qty},
1225 'comment' => $form->{comment}
1228 =head3 Prerequisites
1230 All of these prerequisites have to be trueish, otherwise the function will exit
1231 unsuccessfully with a return value of undef.
1235 =item Mandantory params
1237 assembly_id, qty, login, dst_warehouse_id and dst_bin_id are mandatory.
1239 =item Subset named 'Assembly' of data set 'Part'
1241 assembly_id has to be an id in the table parts with the valid subset assembly.
1243 =item Assembly is composed of assembly item(s)
1245 There has to be at least one data set in the table assembly referenced to this assembly_id.
1247 =item Assembly cannot be destroyed or disassembled
1249 Assemblies are like cakes. You cannot disassemble it. NEVER.
1250 No negative nor zero qty's are valid inputs.
1252 =item The assembly item(s) have to be in the same warehouse
1254 inventory.warehouse_id equals dst_warehouse_id (client configurable).
1256 =item The assembly item(s) have to be in stock with the qty needed
1258 I can only make a cake by receipt if I have ALL ingredients and
1259 in the needed stock amount.
1260 The qty of stocked in assembly item(s) has to fit into the
1261 number of the qty of the assemblies, which are going to be created (client configurable).
1263 =item assembly item(s) with the parts set 'service' are ignored
1265 The subset 'Services' of part will not transferred for assembly item(s).
1269 Client configurable prerequisites can be changed with different
1270 prerequisites as described in client_config (s.a. next chapter).
1273 =head2 default creation of assembly
1275 The valid state of the assembly item(s) used for the assembly process are
1276 'out' for the general direction and 'used' as the specific reason.
1277 The valid state of the assembly is 'in' for the direction and 'assembled'
1278 as the specific reason.
1280 The method is transaction safe, in case of errors not a single entry will be made
1283 Two prerequisites can be changed with this global parameters
1287 =item $::instance_conf->get_transfer_default_warehouse_for_assembly
1289 If trueish we try to get all the items form the default bins defined in parts
1290 and do not try to find them in the destination warehouse. Returns an
1291 error if not all items have set a default bin in parts.
1293 =item $::instance_conf->get_bin_id_ignore_onhand
1295 If trueish we can create assemblies even if we do not have enough items in stock.
1296 The needed qty will be booked in a special bin, which has to be configured in