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) {
84 ($trans_id) = selectrow_query($::form, $::form->get_standard_dbh, qq|SELECT nextval('id')|) if $transfer->{qty};
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_id;
103 if ($transfer->{transfer_type_id}) {
104 $transfer_type_id = $transfer->{transfer_type_id};
106 my $transfer_type = $objectify->($transfer, 'transfer_type', 'SL::DB::TransferType', direction => $directions[$direction],
107 description => $transfer->{transfer_type});
108 $transfer_type_id = $transfer_type->id;
111 my $stocktaking_qty = $transfer->{stocktaking_qty};
115 employee => $employee,
116 trans_type_id => $transfer_type_id,
118 trans_id => $trans_id,
119 shippingdate => !$transfer->{shippingdate} || $transfer->{shippingdate} eq 'current_date'
120 ? $now : $transfer->{shippingdate},
121 map { $_ => $transfer->{$_} } qw(chargenumber bestbefore oe_id delivery_order_items_stock_id invoice_id comment),
125 $qty = $unit->convert_to($qty, $part->unit_obj);
126 $stocktaking_qty = $unit->convert_to($stocktaking_qty, $part->unit_obj);
129 $params{chargenumber} ||= '';
132 if ($qty && $direction & 1) {
133 push @inventories, SL::DB::Inventory->new(
135 warehouse => $src_wh,
141 if ($qty && $direction & 2) {
142 push @inventories, SL::DB::Inventory->new(
144 warehouse => $dst_wh->id,
148 # Standardlagerplatz in Stammdaten gleich mitverschieben
149 if (defined($transfer->{change_default_bin})){
150 $part->update_attributes(warehouse_id => $dst_wh->id, bin_id => $dst_bin->id);
154 # Record stocktaking if requested.
155 # This is only possible if transfer was a stock in or stock out,
156 # but not both (transfer).
157 if ($transfer->{record_stocktaking}) {
158 die 'Stocktaking can only be recorded for stock in or stock out, but not on a transfer.' if scalar @inventories > 1;
161 $inventory_id = $inventories[0]->id if $inventories[0];
163 SL::DB::Stocktaking->new(
164 inventory_id => $inventory_id,
165 warehouse => $src_wh || $dst_wh,
166 bin => $src_bin || $dst_bin,
167 parts_id => $part->id,
168 employee_id => $employee->id,
169 qty => $stocktaking_qty,
170 comment => $transfer->{comment},
171 cutoff_date => $transfer->{stocktaking_cutoff_date},
172 chargenumber => $transfer->{chargenumber},
173 bestbefore => $transfer->{bestbefore},
178 push @trans_ids, $trans_id;
183 $::form->error("Warehouse transfer error: " . join("\n", (split(/\n/, $db->error))[0..2]));
186 $::lxdebug->leave_sub;
191 sub transfer_assembly {
192 $main::lxdebug->enter_sub();
196 Common::check_params(\%params, qw(assembly_id dst_warehouse_id login qty unit dst_bin_id chargenumber bestbefore comment));
198 # my $maxcreate=WH->check_assembly_max_create(assembly_id =>$params{'assembly_id'}, dbh => $my_dbh);
200 my $myconfig = \%main::myconfig;
201 my $form = $main::form;
202 my $kannNichtFertigen =""; # Falls leer dann erfolgreich
204 SL::DB->client->with_transaction(sub {
205 my $dbh = $params{dbh} || SL::DB->client->dbh;
209 # ... Standard-Check oben Ende. Hier die eigentliche SQL-Abfrage
210 # select parts_id,qty from assembly where id=1064;
211 # Erweiterung für bug 935 am 23.4.09 -
212 # Erzeugnisse können Dienstleistungen enthalten, die ja nicht 'lagerbar' sind.
213 # select parts_id,qty from assembly inner join parts on assembly.parts_id = parts.id
214 # where assembly.id=1066 and inventory_accno_id IS NOT NULL;
216 # Erweiterung für bug 23.4.09 -2 Erzeugnisse in Erzeugnissen können nicht ausgelagert werden,
217 # wenn assembly nicht überprüft wird ...
218 # patch von joachim eingespielt 24.4.2009:
219 # my $query = qq|select parts_id,qty from assembly inner join parts
220 # on assembly.parts_id = parts.id where assembly.id = ? and
221 # (inventory_accno_id IS NOT NULL or parts.assembly = TRUE)|;
223 # Lager in dem die Bestandteile gesucht werden kann entweder das Ziellager sein oder ist per Mandantenkonfig
224 # auf das Standardlager des Bestandteiles schaltbar
226 my $use_default_warehouse = $::instance_conf->get_transfer_default_warehouse_for_assembly;
228 my $query = qq|SELECT assembly.parts_id, assembly.qty, parts.warehouse_id
229 FROM assembly INNER JOIN parts ON assembly.parts_id = parts.id
230 WHERE assembly.id = ? AND parts.part_type != 'service'|;
232 my $sth_part_qty_assembly = prepare_execute_query($form, $dbh, $query, $params{assembly_id});
234 # Hier wird das prepared Statement für die Schleife über alle Lagerplätze vorbereitet
235 my $transferPartSQL = qq|INSERT INTO inventory (parts_id, warehouse_id, bin_id, chargenumber, bestbefore, comment, employee_id, qty,
236 trans_id, trans_type_id, shippingdate)
237 VALUES (?, ?, ?, ?, ?, ?, (SELECT id FROM employee WHERE login = ?), ?, nextval('id'),
238 (SELECT id FROM transfer_type WHERE direction = 'out' AND description = 'used'),
239 (SELECT current_date))|;
240 my $sthTransferPartSQL = prepare_query($form, $dbh, $transferPartSQL);
242 # der return-string für die fehlermeldung inkl. welche waren zum fertigen noch fehlen
244 my $schleife_durchlaufen=0; # Falls die Schleife nicht ausgeführt wird -> Keine Einzelteile definiert. Bessere Idee? jan
245 while (my $hash_ref = $sth_part_qty_assembly->fetchrow_hashref()) { #Schleife für select parts_id,(...) from assembly
246 $schleife_durchlaufen=1; # Erzeugnis definiert
248 my $partsQTY = $hash_ref->{qty} * $params{qty}; # benötigte teile * anzahl erzeugnisse
249 my $currentPart_ID = $hash_ref->{parts_id};
251 my $currentPart_WH_ID = $use_default_warehouse && $hash_ref->{warehouse_id} ? $hash_ref->{warehouse_id} : $params{dst_warehouse_id};
254 # Prüfen ob Erzeugnis-Teile Standardlager haben.
255 if ($use_default_warehouse && ! $hash_ref->{warehouse_id}) {
256 # Prüfen ob in Mandantenkonfiguration ein Standardlager aktiviert isti.
257 if ($::instance_conf->get_transfer_default_ignore_onhand) {
258 $currentPart_WH_ID = $::instance_conf->get_warehouse_id_ignore_onhand;
261 $kannNichtFertigen .= "Kein Standardlager: " .
262 " Die Ware " . $self->get_part_description(parts_id => $currentPart_ID) .
263 " hat kein Standardlager definiert " .
264 ", um das Erzeugnis herzustellen. <br>";
268 my $warehouse_info = $self->get_basic_warehouse_info('id'=> $currentPart_WH_ID);
269 my $warehouse_desc = $warehouse_info->{"warehouse_description"};
271 # Fertigen ohne Prüfung nach Bestand
273 my $temppart_bin_id = $::instance_conf->get_bin_id_ignore_onhand;
274 my $temppart_chargenumber = "";
275 my $temppart_bestbefore = localtime();
276 my $temppart_qty = $partsQTY * -1;
278 do_statement($form, $sthTransferPartSQL, $transferPartSQL, $currentPart_ID, $currentPart_WH_ID,
279 $temppart_bin_id, $temppart_chargenumber, $temppart_bestbefore, 'Verbraucht für ' .
280 $self->get_part_description(parts_id => $params{assembly_id}), $params{login}, $temppart_qty);
283 # Überprüfen, ob diese Anzahl gefertigt werden kann
284 my $max_parts = $self->get_max_qty_parts(parts_id => $currentPart_ID, # $self->method() == this.method()
285 warehouse_id => $currentPart_WH_ID);
287 if ($partsQTY > $max_parts){
288 # Gibt es hier ein Problem mit nicht "escapten" Zeichen?
289 # 25.4.09 Antwort: Ja. Aber erst wenn im Frontend die locales-Funktion aufgerufen wird
291 $kannNichtFertigen .= "Zum Fertigen fehlen: " . abs($partsQTY - $max_parts) .
292 " Einheiten der Ware: " . $self->get_part_description(parts_id => $currentPart_ID) .
293 " im Lager: " . $warehouse_desc .
294 ", um das Erzeugnis herzustellen. <br>"; # Konnte die Menge nicht mit der aktuellen Anzahl der Waren fertigen
295 next; # die weiteren Überprüfungen sind unnötig, daher das nächste elemente prüfen (genaue Ausgabe, was noch fehlt)
298 # Eine kurze Vorabfrage, um den Lagerplatz, Chargennummer und die Mindesthaltbarkeit zu bestimmen
299 # Offen: Die Summe über alle Lagerplätze wird noch nicht gebildet
300 # Gelöst: Wir haben vorher schon die Abfrage durchgeführt, ob wir fertigen können.
301 # Noch besser gelöst: Wir laufen durch alle benötigten Waren zum Fertigen und geben eine Rückmeldung an den Benutzer was noch fehlt
302 # und lösen den Rest dann so wie bei xplace im Barcode-Programm
303 # S.a. Kommentar im bin/mozilla-Code mb übernimmt und macht das in ordentlich
305 my $tempquery = qq|SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory
306 WHERE warehouse_id = ? AND parts_id = ? GROUP BY bin_id, chargenumber, bestbefore having SUM(qty)>0|;
307 my $tempsth = prepare_execute_query($form, $dbh, $tempquery, $currentPart_WH_ID, $currentPart_ID);
309 # Alle Werte zu dem einzelnen Artikel, die wir später auslagern
310 my $tmpPartsQTY = $partsQTY;
312 while (my $temphash_ref = $tempsth->fetchrow_hashref()) {
313 my $temppart_bin_id = $temphash_ref->{bin_id}; # kann man hier den quelllagerplatz beim verbauen angeben?
314 my $temppart_chargenumber = $temphash_ref->{chargenumber};
315 my $temppart_bestbefore = conv_date($temphash_ref->{bestbefore});
316 my $temppart_qty = $temphash_ref->{sum};
318 if ($tmpPartsQTY > $temppart_qty) { # wir haben noch mehr waren zum wegbuchen.
319 # Wir buchen den kompletten Lagerplatzbestand und zählen die Hilfsvariable runter
320 $tmpPartsQTY = $tmpPartsQTY - $temppart_qty;
321 $temppart_qty = $temppart_qty * -1; # TODO beim analyiseren des sql-trace, war dieser wert positiv,
322 # wenn * -1 als berechnung in der parameter-übergabe angegeben wird.
323 # Dieser Wert IST und BLEIBT positiv!! Hilfe.
324 # Liegt das daran, dass dieser Wert aus einem SQL-Statement stammt?
325 do_statement($form, $sthTransferPartSQL, $transferPartSQL, $currentPart_ID, $currentPart_WH_ID,
326 $temppart_bin_id, $temppart_chargenumber, $temppart_bestbefore, 'Verbraucht für ' .
327 $self->get_part_description(parts_id => $params{assembly_id}), $params{login}, $temppart_qty);
329 # hier ist noch ein fehler am besten mit definierten erzeugnissen debuggen 02/2009 jb
330 # idee: ausbuch algorithmus mit rekursion lösen und an- und abschaltbar machen
331 # das problem könnte sein, dass strict nicht an war und sth global eine andere zuweisung bekam
332 # auf jeden fall war der internal-server-error nach aktivierung von strict und warnings plus ein paar my-definitionen weg
333 } else { # okay, wir haben weniger oder gleich Waren die wir wegbuchen müssen, wir können also aufhören
335 do_statement($form, $sthTransferPartSQL, $transferPartSQL, $currentPart_ID, $currentPart_WH_ID,
336 $temppart_bin_id, $temppart_chargenumber, $temppart_bestbefore, 'Verbraucht für ' .
337 $self->get_part_description(parts_id => $params{assembly_id}), $params{login}, $tmpPartsQTY);
338 last; # beendet die schleife (springt zum letzten element)
340 } # ende while SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory WHERE warehouse_id
341 } #ende while select parts_id,qty from assembly where id = ?
343 if ($schleife_durchlaufen==0){ # falls die schleife nicht durchlaufen wurde, wurden auch
344 # keine einzelteile definiert
345 $kannNichtFertigen ="Für dieses Erzeugnis sind keine Einzelteile definiert.
346 Dementsprechend kann auch nichts hergestellt werden";
348 # gibt die Fehlermeldung zurück. A.) Keine Teile definiert
349 # B.) Artikel und Anzahl der fehlenden Teile/Dienstleistungen
350 die "<br><br>" . $kannNichtFertigen if ($kannNichtFertigen);
352 # soweit alles gut. Jetzt noch die wirkliche Lagerbewegung für das Erzeugnis ausführen ...
353 my $transferAssemblySQL = qq|INSERT INTO inventory (parts_id, warehouse_id, bin_id, chargenumber, bestbefore,
354 comment, employee_id, qty, trans_id, trans_type_id, shippingdate)
355 VALUES (?, ?, ?, ?, ?, ?, (SELECT id FROM employee WHERE login = ?), ?, nextval('id'),
356 (SELECT id FROM transfer_type WHERE direction = 'in' AND description = 'assembled'),
357 (select current_date))|;
358 my $sthTransferAssemblySQL = prepare_query($form, $dbh, $transferAssemblySQL);
359 do_statement($form, $sthTransferAssemblySQL, $transferAssemblySQL, $params{assembly_id}, $params{dst_warehouse_id},
360 $params{dst_bin_id}, $params{chargenumber}, conv_date($params{bestbefore}), $params{comment}, $params{login}, $params{qty});
362 }) or do { return $kannNichtFertigen };
364 $main::lxdebug->leave_sub();
365 return 1; # Alles erfolgreich
368 sub get_warehouse_journal {
369 $main::lxdebug->enter_sub();
374 my $myconfig = \%main::myconfig;
375 my $form = $main::form;
377 my $all_units = AM->retrieve_units($myconfig, $form);
379 # connect to database
380 my $dbh = $form->get_standard_dbh($myconfig);
383 my (@filter_ary, @filter_vars, $joins, %select_tokens, %select);
385 if ($filter{warehouse_id}) {
386 push @filter_ary, "w1.id = ? OR w2.id = ?";
387 push @filter_vars, $filter{warehouse_id}, $filter{warehouse_id};
390 if ($filter{bin_id}) {
391 push @filter_ary, "b1.id = ? OR b2.id = ?";
392 push @filter_vars, $filter{bin_id}, $filter{bin_id};
395 if ($filter{partnumber}) {
396 push @filter_ary, "p.partnumber ILIKE ?";
397 push @filter_vars, like($filter{partnumber});
400 if ($filter{description}) {
401 push @filter_ary, "(p.description ILIKE ?)";
402 push @filter_vars, like($filter{description});
405 if ($filter{classification_id}) {
406 push @filter_ary, "p.classification_id = ?";
407 push @filter_vars, $filter{classification_id};
410 if ($filter{chargenumber}) {
411 push @filter_ary, "i1.chargenumber ILIKE ?";
412 push @filter_vars, like($filter{chargenumber});
415 if (trim($form->{bestbefore})) {
416 push @filter_ary, "?::DATE = i1.bestbefore::DATE";
417 push @filter_vars, trim($form->{bestbefore});
420 if (trim($form->{fromdate})) {
421 push @filter_ary, "? <= i1.shippingdate";
422 push @filter_vars, trim($form->{fromdate});
425 if (trim($form->{todate})) {
426 push @filter_ary, "? >= i1.shippingdate";
427 push @filter_vars, trim($form->{todate});
430 if ($form->{l_employee}) {
434 # prepare qty comparison for later filtering
435 my ($f_qty_op, $f_qty, $f_qty_base_unit);
436 if ($filter{qty_op} && defined($filter{qty}) && $filter{qty_unit} && $all_units->{$filter{qty_unit}}) {
437 $f_qty_op = $filter{qty_op};
438 $f_qty = $filter{qty} * $all_units->{$filter{qty_unit}}->{factor};
439 $f_qty_base_unit = $all_units->{$filter{qty_unit}}->{base_unit};
442 map { $_ = "(${_})"; } @filter_ary;
444 # if of a property number or description is requested,
445 # automatically check the matching id too.
446 map { $form->{"l_${_}id"} = "Y" if ($form->{"l_${_}description"} || $form->{"l_${_}number"}); } qw(warehouse bin);
448 # customize shown entry for not available fields.
449 $filter{na} = '-' unless $filter{na};
451 # make order, search in $filter and $form
452 my $sort_col = $form->{sort};
453 my $sort_order = $form->{order};
455 $sort_col = $filter{sort} unless $sort_col;
456 $sort_col = 'shippingdate' if $sort_col eq 'date';
457 $sort_order = ($sort_col = 'shippingdate') unless $sort_col;
460 'shippingdate' => ['shippingdate', 'r_itime', 'r_parts_id'],
461 'bin_to' => ['bin_to', 'r_itime', 'r_parts_id'],
462 'bin_from' => ['bin_from', 'r_itime', 'r_parts_id'],
463 'warehouse_to' => ['warehouse_to, r_itime, r_parts_id'],
464 'warehouse_from' => ['warehouse_from, r_itime, r_parts_id'],
465 'partnumber' => ['partnumber'],
466 'partdescription'=> ['partdescription'],
467 'partunit' => ['partunit, r_itime, r_parts_id'],
468 'qty' => ['qty, r_itime, r_parts_id'],
469 'oe_id' => ['oe_id'],
470 'comment' => ['comment'],
471 'trans_type' => ['trans_type'],
472 'employee' => ['employee'],
473 'projectnumber' => ['projectnumber'],
474 'chargenumber' => ['chargenumber'],
477 $sort_order = $filter{order} unless $sort_order;
478 my $ASC = ($sort_order ? " DESC" : " ASC");
479 my $sort_spec = join("$ASC , ", @{$orderspecs{$sort_col}}). " $ASC";
481 my $where_clause = @filter_ary ? join(" AND ", @filter_ary) . " AND " : '';
483 $select_tokens{'trans'} = {
484 "parts_id" => "i1.parts_id",
485 "qty" => "ABS(SUM(i1.qty))",
486 "partnumber" => "p.partnumber",
487 "partdescription" => "p.description",
488 "classification_id" => "p.classification_id",
489 "part_type" => "p.part_type",
490 "bindescription" => "b.description",
491 "chargenumber" => "i1.chargenumber",
492 "bestbefore" => "i1.bestbefore",
493 "warehousedescription" => "w.description",
494 "partunit" => "p.unit",
495 "bin_from" => "b1.description",
496 "bin_to" => "b2.description",
497 "warehouse_from" => "w1.description",
498 "warehouse_to" => "w2.description",
499 "comment" => "i1.comment",
500 "trans_type" => "tt.description",
501 "trans_id" => "i1.trans_id",
502 "oe_id" => "COALESCE(i1.oe_id, i2.oe_id)",
503 "invoice_id" => "COALESCE(i1.invoice_id, i2.invoice_id)",
504 "date" => "i1.shippingdate",
505 "itime" => "i1.itime",
506 "shippingdate" => "i1.shippingdate",
507 "employee" => "e.name",
508 "projectnumber" => "COALESCE(pr.projectnumber, '$filter{na}')",
511 $select_tokens{'out'} = {
512 "bin_to" => "'$filter{na}'",
513 "warehouse_to" => "'$filter{na}'",
516 $select_tokens{'in'} = {
517 "bin_from" => "'$filter{na}'",
518 "warehouse_from" => "'$filter{na}'",
521 $form->{l_classification_id} = 'Y';
522 $form->{l_part_type} = 'Y';
523 $form->{l_itime} = 'Y';
524 $form->{l_invoice_id} = $form->{l_oe_id} if $form->{l_oe_id};
526 # build the select clauses.
527 # take all the requested ones from the first hash and overwrite them from the out/in hashes if present.
528 for my $i ('trans', 'out', 'in') {
529 $select{$i} = join ', ', map { +/^l_/; ($select_tokens{$i}{"$'"} || $select_tokens{'trans'}{"$'"}) . " AS r_$'" }
530 ( grep( { !/qty$/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form), qw(l_parts_id l_qty l_partunit l_shippingdate) );
533 my $group_clause = join ", ", map { +/^l_/; "r_$'" }
534 ( grep( { !/qty$/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form), qw(l_parts_id l_partunit l_shippingdate l_itime) );
536 $where_clause = defined($where_clause) ? $where_clause : '';
539 qq|SELECT * FROM (SELECT DISTINCT $select{trans}
541 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
542 LEFT JOIN parts p ON i1.parts_id = p.id
543 LEFT JOIN bin b1 ON i1.bin_id = b1.id
544 LEFT JOIN bin b2 ON i2.bin_id = b2.id
545 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
546 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
547 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
548 LEFT JOIN project pr ON i1.project_id = pr.id
549 LEFT JOIN employee e ON i1.employee_id = e.id
550 WHERE $where_clause i2.qty = -i1.qty AND i2.qty > 0 AND
551 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 2 )
552 GROUP BY $group_clause
556 SELECT DISTINCT $select{out}
558 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
559 LEFT JOIN parts p ON i1.parts_id = p.id
560 LEFT JOIN bin b1 ON i1.bin_id = b1.id
561 LEFT JOIN bin b2 ON i2.bin_id = b2.id
562 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
563 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
564 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
565 LEFT JOIN project pr ON i1.project_id = pr.id
566 LEFT JOIN employee e ON i1.employee_id = e.id
567 WHERE $where_clause i1.qty < 0 AND
568 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 1 )
569 GROUP BY $group_clause
573 SELECT DISTINCT $select{in}
575 LEFT JOIN inventory i2 ON i1.trans_id = i2.trans_id
576 LEFT JOIN parts p ON i1.parts_id = p.id
577 LEFT JOIN bin b1 ON i1.bin_id = b1.id
578 LEFT JOIN bin b2 ON i2.bin_id = b2.id
579 LEFT JOIN warehouse w1 ON i1.warehouse_id = w1.id
580 LEFT JOIN warehouse w2 ON i2.warehouse_id = w2.id
581 LEFT JOIN transfer_type tt ON i1.trans_type_id = tt.id
582 LEFT JOIN project pr ON i1.project_id = pr.id
583 LEFT JOIN employee e ON i1.employee_id = e.id
584 WHERE $where_clause i1.qty > 0 AND
585 i1.trans_id IN ( SELECT i.trans_id FROM inventory i GROUP BY i.trans_id HAVING COUNT(i.trans_id) = 1 )
586 GROUP BY $group_clause
587 ORDER BY r_${sort_spec}) AS lines WHERE r_qty>0|;
589 my @all_vars = (@filter_vars,@filter_vars,@filter_vars);
591 if ($filter{limit}) {
592 $query .= " LIMIT ?";
593 push @all_vars,$filter{limit};
595 if ($filter{offset}) {
596 $query .= " OFFSET ?";
597 push @all_vars, $filter{offset};
600 my $sth = prepare_execute_query($form, $dbh, $query, @all_vars);
602 my ($h_oe_id, $q_oe_id);
603 if ($form->{l_oe_id}) {
605 SELECT dord.id AS id, dord.donumber AS number,
607 WHEN dord.customer_id IS NULL THEN 'purchase_delivery_order'
608 ELSE 'sales_delivery_order'
610 FROM delivery_orders dord
615 SELECT ar.id AS id, ar.invnumber AS number, 'sales_invoice' AS type
617 WHERE ar.id = (SELECT trans_id FROM invoice WHERE id = ?)
621 SELECT ap.id AS id, ap.invnumber AS number, 'purchase_invoice' AS type
623 WHERE ap.id = (SELECT trans_id FROM invoice WHERE id = ?)
625 $h_oe_id = prepare_query($form, $dbh, $q_oe_id);
629 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
630 map { /^r_/; $ref->{"$'"} = $ref->{$_} } keys %$ref;
631 my $qty = $ref->{"qty"} * 1;
633 next unless ($qty > 0);
636 my $part_unit = $all_units->{$ref->{"partunit"}};
637 next unless ($part_unit && ($part_unit->{"base_unit"} eq $f_qty_base_unit));
638 $qty *= $part_unit->{"factor"};
639 next if (('=' eq $f_qty_op) && ($qty != $f_qty));
640 next if (('>=' eq $f_qty_op) && ($qty < $f_qty));
641 next if (('<=' eq $f_qty_op) && ($qty > $f_qty));
644 if ($h_oe_id && ($ref->{oe_id} || $ref->{invoice_id})) {
645 do_statement($form, $h_oe_id, $q_oe_id, $ref->{oe_id}, ($ref->{invoice_id}) x 2);
646 $ref->{oe_id_info} = $h_oe_id->fetchrow_hashref() || {};
649 push @contents, $ref;
653 $h_oe_id->finish() if $h_oe_id;
655 $main::lxdebug->leave_sub();
661 # This sub is the primary function to retrieve information about items in warehouses.
662 # $filter is a hashref and supports the following keys:
663 # - warehouse_id - will return matches with this warehouse_id only
664 # - partnumber - will return only matches where the given string is a substring of the partnumber
665 # - partsid - will return matches with this parts_id only
666 # - classification_id - will return matches with this parts with this classification only
667 # - description - will return only matches where the given string is a substring of the description
668 # - chargenumber - will return only matches where the given string is a substring of the chargenumber
669 # - bestbefore - will return only matches with this bestbefore date
670 # - ean - will return only matches where the given string is a substring of the ean as stored in the table parts (article)
671 # - charge_ids - must be an arrayref. will return contents with these ids only
672 # - expires_in - will only return matches that expire within the given number of days
673 # will also add a column named 'has_expired' containing if the match has already expired or not
674 # - hazardous - will return matches with the flag hazardous only
675 # - oil - will return matches with the flag oil only
676 # - qty, qty_op - quantity filter (more info to come)
677 # - sort, order_by - sorting (more to come)
678 # - reservation - will provide an extra column containing the amount reserved of this match
679 # note: reservation flag turns off warehouse_* or bin_* information. both together don't make sense, since reserved info is stored separately
681 sub get_warehouse_report {
682 $main::lxdebug->enter_sub();
687 my $myconfig = \%main::myconfig;
688 my $form = $main::form;
690 my $all_units = AM->retrieve_units($myconfig, $form);
692 # connect to database
693 my $dbh = $form->get_standard_dbh($myconfig);
696 my (@filter_ary, @filter_vars, @wh_bin_filter_ary, @wh_bin_filter_vars);
698 delete $form->{include_empty_bins} unless ($form->{l_warehousedescription} || $form->{l_bindescription});
700 if ($filter{warehouse_id}) {
701 push @wh_bin_filter_ary, "w.id = ?";
702 push @wh_bin_filter_vars, $filter{warehouse_id};
705 if ($filter{bin_id}) {
706 push @wh_bin_filter_ary, "b.id = ?";
707 push @wh_bin_filter_vars, $filter{bin_id};
710 push @filter_ary, @wh_bin_filter_ary;
711 push @filter_vars, @wh_bin_filter_vars;
713 if ($filter{partnumber}) {
714 push @filter_ary, "p.partnumber ILIKE ?";
715 push @filter_vars, like($filter{partnumber});
718 if ($filter{classification_id}) {
719 push @filter_ary, "p.classification_id = ?";
720 push @filter_vars, $filter{classification_id};
723 if ($filter{description}) {
724 push @filter_ary, "p.description ILIKE ?";
725 push @filter_vars, like($filter{description});
728 if ($filter{partsid}) {
729 push @filter_ary, "p.id = ?";
730 push @filter_vars, $filter{partsid};
733 if ($filter{chargenumber}) {
734 push @filter_ary, "i.chargenumber ILIKE ?";
735 push @filter_vars, like($filter{chargenumber});
738 if (trim($form->{bestbefore})) {
739 push @filter_ary, "?::DATE = i.bestbefore::DATE";
740 push @filter_vars, trim($form->{bestbefore});
743 if ($filter{classification_id}) {
744 push @filter_ary, "p.classification_id = ?";
745 push @filter_vars, $filter{classification_id};
749 push @filter_ary, "p.ean ILIKE ?";
750 push @filter_vars, like($filter{ean});
753 if (trim($filter{date})) {
754 push @filter_ary, "i.shippingdate <= ?";
755 push @filter_vars, trim($filter{date});
757 if (!$filter{include_invalid_warehouses}){
758 push @filter_ary, "NOT (w.invalid)";
761 # prepare qty comparison for later filtering
762 my ($f_qty_op, $f_qty, $f_qty_base_unit);
764 if ($filter{qty_op} && defined $filter{qty} && $filter{qty_unit} && $all_units->{$filter{qty_unit}}) {
765 $f_qty_op = $filter{qty_op};
766 $f_qty = $filter{qty} * $all_units->{$filter{qty_unit}}->{factor};
767 $f_qty_base_unit = $all_units->{$filter{qty_unit}}->{base_unit};
770 map { $_ = "(${_})"; } @filter_ary;
772 # if of a property number or description is requested,
773 # automatically check the matching id too.
774 map { $form->{"l_${_}id"} = "Y" if ($form->{"l_${_}description"} || $form->{"l_${_}number"}); } qw(warehouse bin);
776 # make order, search in $filter and $form
777 my $sort_col = $form->{sort};
778 my $sort_order = $form->{order};
780 $sort_col = $filter{sort} unless $sort_col;
781 # falls $sort_col gar nicht in dem Bericht aufgenommen werden soll,
782 # führt ein entsprechenes order by $sort_col zu einem SQL-Fehler
783 # entsprechend parts_id als default lassen, wenn $sort_col UND l_$sort_col
784 # vorhanden sind (bpsw. l_partnumber = 'Y', für in Bericht aufnehmen).
785 # S.a. Bug 1597 jb 12.5.2011
786 $sort_col = "parts_id" unless ($sort_col && $form->{"l_$sort_col"});
787 $sort_order = $filter{order} unless $sort_order;
788 $sort_col =~ s/ASC|DESC//; # kill stuff left in from previous queries
789 my $orderby = $sort_col;
790 my $sort_spec = "${sort_col} " . ($sort_order ? " DESC" : " ASC");
792 my $where_clause = join " AND ", ("1=1", @filter_ary);
794 my %select_tokens = (
795 "parts_id" => "i.parts_id",
796 "qty" => "SUM(i.qty)",
797 "warehouseid" => "i.warehouse_id",
798 "partnumber" => "p.partnumber",
799 "partdescription" => "p.description",
800 "classification_id" => "p.classification_id",
801 "part_type" => "p.part_type",
802 "bindescription" => "b.description",
804 "chargenumber" => "i.chargenumber",
805 "bestbefore" => "i.bestbefore",
807 "chargeid" => "c.id",
808 "warehousedescription" => "w.description",
809 "partunit" => "p.unit",
810 "stock_value" => ($form->{stock_value_basis} // '') eq 'list_price' ? "p.listprice / COALESCE(pfac.factor, 1)" : "p.lastcost / COALESCE(pfac.factor, 1)",
811 "purchase_price" => "p.lastcost",
812 "list_price" => "p.listprice",
814 $form->{l_classification_id} = 'Y';
815 $form->{l_part_type} = 'Y';
817 my $select_clause = join ', ', map { +/^l_/; "$select_tokens{$'} AS $'" }
818 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
819 qw(l_parts_id l_qty l_partunit) );
821 my $group_clause = join ", ", map { +/^l_/; "$'" }
822 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
823 qw(l_parts_id l_partunit) );
826 "stock_value" => "LEFT JOIN price_factors pfac ON (p.price_factor_id = pfac.id)",
829 my $joins = join ' ', grep { $_ } map { +/^l_/; $join_tokens{"$'"} }
830 ( grep( { !/qty/ and /^l_/ and $form->{$_} eq 'Y' } keys %$form),
831 qw(l_parts_id l_qty l_partunit) );
834 qq|SELECT * FROM ( SELECT $select_clause
836 LEFT JOIN parts p ON i.parts_id = p.id
837 LEFT JOIN bin b ON i.bin_id = b.id
838 LEFT JOIN warehouse w ON i.warehouse_id = w.id
841 GROUP BY $group_clause
842 ORDER BY $sort_spec ) AS lines WHERE qty<>0|;
844 if ($filter{limit}) {
845 $query .= " LIMIT ?";
846 push @filter_vars,$filter{limit};
848 if ($filter{offset}) {
849 $query .= " OFFSET ?";
850 push @filter_vars, $filter{offset};
852 my $sth = prepare_execute_query($form, $dbh, $query, @filter_vars );
854 my (%non_empty_bins, @all_fields, @contents);
856 while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
858 my $qty = $ref->{qty};
860 next unless ($qty != 0);
863 my $part_unit = $all_units->{$ref->{partunit}};
864 next if (!$part_unit || ($part_unit->{base_unit} ne $f_qty_base_unit));
865 $qty *= $part_unit->{factor};
866 next if (('=' eq $f_qty_op) && ($qty != $f_qty));
867 next if (('>=' eq $f_qty_op) && ($qty < $f_qty));
868 next if (('<=' eq $f_qty_op) && ($qty > $f_qty));
871 if ($form->{include_empty_bins}) {
872 $non_empty_bins{$ref->{binid}} = 1;
873 @all_fields = keys %{ $ref } unless (@all_fields);
876 $ref->{stock_value} = ($ref->{stock_value} || 0) * $ref->{qty};
878 push @contents, $ref;
883 if ($form->{include_empty_bins}) {
886 w.id AS warehouseid, w.description AS warehousedescription,
887 b.id AS binid, b.description AS bindescription
889 LEFT JOIN warehouse w ON (b.warehouse_id = w.id)|;
891 @filter_ary = @wh_bin_filter_ary;
892 @filter_vars = @wh_bin_filter_vars;
894 my @non_empty_bin_ids = keys %non_empty_bins;
895 if (@non_empty_bin_ids) {
896 push @filter_ary, qq|NOT b.id IN (| . join(', ', map { '?' } @non_empty_bin_ids) . qq|)|;
897 push @filter_vars, @non_empty_bin_ids;
900 $query .= qq| WHERE | . join(' AND ', map { "($_)" } @filter_ary) if (@filter_ary);
902 $sth = prepare_execute_query($form, $dbh, $query, @filter_vars);
904 while (my $ref = $sth->fetchrow_hashref()) {
905 map { $ref->{$_} ||= "" } @all_fields;
906 push @contents, $ref;
910 if (grep { $orderby eq $_ } qw(bindescription warehousedescription)) {
911 @contents = sort { ($a->{$orderby} cmp $b->{$orderby}) * (($form->{order}) ? 1 : -1) } @contents;
915 $main::lxdebug->leave_sub();
921 $main::lxdebug->enter_sub();
923 my ($self, $qty_op) = @_;
925 if (!$qty_op || ($qty_op eq "dontcare")) {
926 $main::lxdebug->leave_sub();
930 if ($qty_op eq "atleast") {
932 } elsif ($qty_op eq "atmost") {
938 $main::lxdebug->leave_sub();
943 sub retrieve_transfer_types {
944 $main::lxdebug->enter_sub();
947 my $direction = shift;
949 my $myconfig = \%main::myconfig;
950 my $form = $main::form;
952 my $dbh = $form->get_standard_dbh($myconfig);
954 my $types = selectall_hashref_query($form, $dbh, qq|SELECT * FROM transfer_type WHERE direction = ? ORDER BY sortkey|, $direction);
956 $main::lxdebug->leave_sub();
961 sub get_basic_bin_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 b.id AS bin_id, b.description AS bin_description,
978 w.id AS warehouse_id, w.description AS warehouse_description
980 LEFT JOIN warehouse w ON (b.warehouse_id = w.id)
981 WHERE b.id IN (| . join(', ', ('?') x scalar(@ids)) . qq|)|;
983 my $result = selectall_hashref_query($form, $dbh, $query, map { conv_i($_) } @ids);
985 if ('' eq ref $params{id}) {
986 $result = $result->[0] || { };
987 $main::lxdebug->leave_sub();
992 $main::lxdebug->leave_sub();
994 return map { $_->{bin_id} => $_ } @{ $result };
997 sub get_basic_warehouse_info {
998 $main::lxdebug->enter_sub();
1003 Common::check_params(\%params, qw(id));
1005 my $myconfig = \%main::myconfig;
1006 my $form = $main::form;
1008 my $dbh = $params{dbh} || $form->get_standard_dbh();
1010 my @ids = 'ARRAY' eq ref $params{id} ? @{ $params{id} } : ($params{id});
1013 qq|SELECT w.id AS warehouse_id, w.description AS warehouse_description
1015 WHERE w.id IN (| . join(', ', ('?') x scalar(@ids)) . qq|)|;
1017 my $result = selectall_hashref_query($form, $dbh, $query, map { conv_i($_) } @ids);
1019 if ('' eq ref $params{id}) {
1020 $result = $result->[0] || { };
1021 $main::lxdebug->leave_sub();
1026 $main::lxdebug->leave_sub();
1028 return map { $_->{warehouse_id} => $_ } @{ $result };
1031 # Eingabe: Teilenummer, Lagernummer (warehouse)
1032 # Ausgabe: Die maximale Anzahl der Teile in diesem Lager
1034 sub get_max_qty_parts {
1035 $main::lxdebug->enter_sub();
1040 Common::check_params(\%params, qw(parts_id warehouse_id)); #die brauchen wir
1042 my $myconfig = \%main::myconfig;
1043 my $form = $main::form;
1045 my $dbh = $params{dbh} || $form->get_standard_dbh();
1047 my $query = qq| SELECT SUM(qty), bin_id, chargenumber, bestbefore FROM inventory where parts_id = ? AND warehouse_id = ? GROUP BY bin_id, chargenumber, bestbefore|;
1048 my $sth_QTY = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}, $params{warehouse_id}); #info: aufruf an DBUtils.pm
1051 my $max_qty_parts = 0; #Initialisierung mit 0
1052 while (my $ref = $sth_QTY->fetchrow_hashref()) { # wir laufen über alle Haltbarkeiten, chargen und Lagerorte (s.a. SQL-Query oben)
1053 $max_qty_parts += $ref->{sum};
1056 $main::lxdebug->leave_sub();
1058 return $max_qty_parts;
1062 # Eingabe: Teilenummer, Lagernummer (warehouse)
1063 # Ausgabe: Die Beschreibung der Ware bzw. Erzeugnis
1065 sub get_part_description {
1066 $main::lxdebug->enter_sub();
1071 Common::check_params(\%params, qw(parts_id)); #die brauchen wir
1073 my $myconfig = \%main::myconfig;
1074 my $form = $main::form;
1076 my $dbh = $params{dbh} || $form->get_standard_dbh();
1078 my $query = qq| SELECT partnumber, description FROM parts where id = ? |;
1080 my $sth = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}); #info: aufruf zu DBUtils.pm
1082 my $ref = $sth->fetchrow_hashref();
1083 my $part_description = $ref->{partnumber} . " " . $ref->{description};
1085 $main::lxdebug->leave_sub();
1087 return $part_description;
1090 # Eingabe: Teilenummer, Lagerplatz_Id (bin_id)
1091 # Ausgabe: Die maximale Anzahl der Teile in diesem Lagerplatz
1092 # Bzw. Fehler, falls Chargen oder bestbefore
1093 # bei eingelagerten Teilen definiert sind.
1095 sub get_max_qty_parts_bin {
1096 $main::lxdebug->enter_sub();
1101 Common::check_params(\%params, qw(parts_id bin_id)); #die brauchen wir
1103 my $myconfig = \%main::myconfig;
1104 my $form = $main::form;
1106 my $dbh = $params{dbh} || $form->get_standard_dbh();
1108 my $query = qq| SELECT SUM(qty), chargenumber, bestbefore FROM inventory where parts_id = ?
1109 AND bin_id = ? GROUP BY chargenumber, bestbefore|;
1111 my $sth_QTY = prepare_execute_query($form, $dbh, $query, ,$params{parts_id}, $params{bin_id}); #info: aufruf an DBUtils.pm
1113 my $max_qty_parts = 0; #Initialisierung mit 0
1114 # falls derselbe artikel mehrmals eingelagert ist
1115 # chargennummer, muss entsprechend händisch agiert werden
1118 while (my $ref = $sth_QTY->fetchrow_hashref()) { # wir laufen über alle Haltbarkeiten und Chargen(s.a. SQL-Query oben)
1119 $max_qty_parts += $ref->{sum};
1121 if (($ref->{chargenumber} || $ref->{bestbefore}) && $ref->{sum} != 0){
1125 $main::lxdebug->leave_sub();
1127 return ($max_qty_parts, $error);
1136 SL::WH - Warehouse backend
1141 WH->transfer(\%params);
1145 Backend for kivitendo warehousing functions.
1149 =head2 transfer \%PARAMS, [ \%PARAMS, ... ]
1151 This is the main function to manipulate warehouse contents. A typical transfer
1152 is called like this:
1157 transfer_type => 'transfer',
1158 src_warehouse_id => 12,
1160 dst_warehouse_id => 25,
1164 It will generate an entry in inventory representing the transfer. Note that
1165 parts_id, qty, and transfer_type are mandatory. Depending on the transfer_type
1166 a destination or a src is mandatory.
1168 transfer accepts more than one transaction parameter, each being a hash ref. If
1169 more than one is supplied, it is guaranteed, that all are processed in the same
1172 It is possible to record stocktakings within this transaction as well.
1173 This is useful if the transfer is the result of stocktaking (see also
1174 C<SL::Controller::Inventory>). To do so the parameters C<record_stocktaking>,
1175 C<stocktaking_qty> and C<stocktaking_cutoff_date> hava to be given.
1176 If stocktaking should be saved, then the transfer quantity can be zero. In this
1177 case no entry in inventory will be made, but only the stocktaking entry.
1179 Here is a full list of parameters. All "_id" parameters except oe and
1180 orderitems can be called without id with RDB objects as well.
1186 The id of the article transferred. Does not check if the article is a service.
1191 Quantity of the transaction. Mandatory.
1195 Unit of the transaction. Optional.
1199 =item transfer_type_id
1201 The type of transaction. The first version is a string describing the
1202 transaction (the types 'transfer' 'in' 'out' and a few others are present on
1203 every system), the id is the hard id of a transfer_type from the database.
1205 Depending of the direction of the transfer_type, source and/or destination must
1208 One of transfer_type or transfer_type_id is mandatory.
1210 =item src_warehouse_id
1214 Warehouse and bin from which to transfer. Mandatory in transfer and out
1215 directions. Ignored in in directions.
1217 =item dst_warehouse_id
1221 Warehouse and bin to which to transfer. Mandatory in transfer and in
1222 directions. Ignored in out directions.
1226 If given, the transfer will transfer only articles with this chargenumber.
1231 Reference to an orderitem for which this transfer happened. Optional
1235 Reference to an order for which this transfer happened. Optional
1239 An optional comment.
1243 An expiration date. Note that this is not by default used by C<warehouse_report>.
1245 =item record_stocktaking
1247 A boolean flag to indicate that a stocktaking entry should be saved.
1249 =item stocktaking_qty
1251 The quantity for the stocktaking entry.
1253 =item stocktaking_cutoff_date
1255 The cutoff date for the stocktaking entry.
1259 =head2 create_assembly \%PARAMS, [ \%PARAMS, ... ]
1261 Creates an assembly if all defined items are available.
1263 Assembly item(s) will be stocked out and the assembly will be stocked in,
1264 taking into account the qty and units which can be defined for each
1265 assembly item separately.
1267 The calling params originate from C<transfer> but only parts_id with the
1268 attribute assembly are processed.
1270 The typical params would be:
1273 'login' => $::myconfig{login},
1274 'dst_warehouse_id' => $form->{warehouse_id},
1275 'dst_bin_id' => $form->{bin_id},
1276 'chargenumber' => $form->{chargenumber},
1277 'bestbefore' => $form->{bestbefore},
1278 'assembly_id' => $form->{parts_id},
1279 'qty' => $form->{qty},
1280 'comment' => $form->{comment}
1283 =head3 Prerequisites
1285 All of these prerequisites have to be trueish, otherwise the function will exit
1286 unsuccessfully with a return value of undef.
1290 =item Mandantory params
1292 assembly_id, qty, login, dst_warehouse_id and dst_bin_id are mandatory.
1294 =item Subset named 'Assembly' of data set 'Part'
1296 assembly_id has to be an id in the table parts with the valid subset assembly.
1298 =item Assembly is composed of assembly item(s)
1300 There has to be at least one data set in the table assembly referenced to this assembly_id.
1302 =item Assembly cannot be destroyed or disassembled
1304 Assemblies are like cakes. You cannot disassemble it. NEVER.
1305 No negative nor zero qty's are valid inputs.
1307 =item The assembly item(s) have to be in the same warehouse
1309 inventory.warehouse_id equals dst_warehouse_id (client configurable).
1311 =item The assembly item(s) have to be in stock with the qty needed
1313 I can only make a cake by receipt if I have ALL ingredients and
1314 in the needed stock amount.
1315 The qty of stocked in assembly item(s) has to fit into the
1316 number of the qty of the assemblies, which are going to be created (client configurable).
1318 =item assembly item(s) with the parts set 'service' are ignored
1320 The subset 'Services' of part will not transferred for assembly item(s).
1324 Client configurable prerequisites can be changed with different
1325 prerequisites as described in client_config (s.a. next chapter).
1328 =head2 default creation of assembly
1330 The valid state of the assembly item(s) used for the assembly process are
1331 'out' for the general direction and 'used' as the specific reason.
1332 The valid state of the assembly is 'in' for the direction and 'assembled'
1333 as the specific reason.
1335 The method is transaction safe, in case of errors not a single entry will be made
1338 Two prerequisites can be changed with these global parameters
1342 =item $::instance_conf->get_transfer_default_warehouse_for_assembly
1344 If trueish we try to get all the items form the default bins defined in parts
1345 and do not try to find them in the destination warehouse. Returns an
1346 error if not all items have set a default bin in parts.
1348 =item $::instance_conf->get_bin_id_ignore_onhand
1350 If trueish we can create assemblies even if we do not have enough items in stock.
1351 The needed qty will be booked in a special bin, which has to be configured in