summaryrefslogtreecommitdiff
path: root/LedgerSMB/IC.pm
blob: 7c61ef925194696bec117bf4caa99e1b834b0fc6 (plain)
  1. #=====================================================================
  2. # LedgerSMB
  3. # Small Medium Business Accounting software
  4. # http://www.ledgersmb.org/
  5. #
  6. # Copyright (C) 2006
  7. # This work contains copyrighted information from a number of sources all used
  8. # with permission.
  9. #
  10. # This file contains source code included with or based on SQL-Ledger which
  11. # is Copyright Dieter Simader and DWS Systems Inc. 2000-2005 and licensed
  12. # under the GNU General Public License version 2 or, at your option, any later
  13. # version. For a full list including contact information of contributors,
  14. # maintainers, and copyright holders, see the CONTRIBUTORS file.
  15. #
  16. # Original Copyright Notice from SQL-Ledger 2.6.17 (before the fork):
  17. # Copyright (C) 2000
  18. #
  19. # Author: DWS Systems Inc.
  20. # Web: http://www.sql-ledger.org
  21. #
  22. # Contributors:
  23. #
  24. #======================================================================
  25. #
  26. # This file has NOT undergone whitespace cleanup.
  27. #
  28. #======================================================================
  29. #
  30. # Inventory Control backend
  31. #
  32. #======================================================================
  33. package IC;
  34. sub get_part {
  35. my ($self, $myconfig, $form) = @_;
  36. # connect to db
  37. my $dbh = $form->{dbh};
  38. my $i;
  39. my $query = qq|
  40. SELECT p.*, c1.accno AS inventory_accno,
  41. c1.description AS inventory_description,
  42. c2.accno AS income_accno,
  43. c2.description AS income_description,
  44. c3.accno AS expense_accno,
  45. c3.description AS expense_description, pg.partsgroup
  46. FROM parts p
  47. LEFT JOIN chart c1 ON (p.inventory_accno_id = c1.id)
  48. LEFT JOIN chart c2 ON (p.income_accno_id = c2.id)
  49. LEFT JOIN chart c3 ON (p.expense_accno_id = c3.id)
  50. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  51. WHERE p.id = ?|;
  52. my $sth = $dbh->prepare($query);
  53. $sth->execute($form->{id}) || $form->dberror($query);
  54. my $ref = $sth->fetchrow_hashref(NAME_lc);
  55. # copy to $form variables
  56. for (keys %$ref) { $form->{$_} = $ref->{$_} }
  57. $sth->finish;
  58. # part, service item or labor
  59. $form->{item} = ($form->{inventory_accno_id}) ? 'part' : 'service';
  60. $form->{item} = 'labor' if ! $form->{income_accno_id};
  61. if ($form->{assembly}) {
  62. $form->{item} = 'assembly';
  63. # retrieve assembly items
  64. $query = qq|
  65. SELECT p.id, p.partnumber, p.description,
  66. p.sellprice, p.weight, a.qty, a.bom, a.adj,
  67. p.unit, p.lastcost, p.listprice,
  68. pg.partsgroup, p.assembly, p.partsgroup_id
  69. FROM parts p
  70. JOIN assembly a ON (a.parts_id = p.id)
  71. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  72. WHERE a.id = ?|;
  73. $sth = $dbh->prepare($query);
  74. $sth->execute($form->{id}) || $form->dberror($query);
  75. $form->{assembly_rows} = 0;
  76. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  77. $form->{assembly_rows}++;
  78. foreach my $key ( keys %{ $ref } ) {
  79. $form->{"${key}_$form->{assembly_rows}"}
  80. = $ref->{$key};
  81. }
  82. }
  83. $sth->finish;
  84. }
  85. # setup accno hash for <option checked>
  86. # {amount} is used in create_links
  87. for (qw(inventory income expense)) {
  88. $form->{amount}{"IC_$_"}
  89. = {
  90. accno => $form->{"${_}_accno"},
  91. description => $form->{"${_}_description"}
  92. };
  93. };
  94. if ($form->{item} =~ /(part|assembly)/) {
  95. if ($form->{makemodel} ne "") {
  96. $query = qq|
  97. SELECT make, model
  98. FROM makemodel
  99. WHERE parts_id = ?|;
  100. $sth = $dbh->prepare($query);
  101. $sth->execute($form->{id}) || $form->dberror($query);
  102. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  103. push @{ $form->{makemodels} }, $ref;
  104. }
  105. $sth->finish;
  106. }
  107. }
  108. # now get accno for taxes
  109. $query = qq|
  110. SELECT c.accno FROM chart c, partstax pt
  111. WHERE pt.chart_id = c.id AND pt.parts_id = ?|;
  112. $sth = $dbh->prepare($query);
  113. $sth->execute($form->{id}) || $form->dberror($query);
  114. while (($key) = $sth->fetchrow_array) {
  115. $form->{amount}{$key} = $key;
  116. }
  117. $sth->finish;
  118. my $id = $dbh->quote($form->{id});
  119. # is it an orphan
  120. $query = qq|
  121. SELECT parts_id FROM invoice WHERE parts_id = $id
  122. UNION
  123. SELECT parts_id FROM orderitems WHERE parts_id = $id
  124. UNION
  125. SELECT parts_id FROM assembly WHERE parts_id = $id
  126. UNION
  127. SELECT parts_id FROM jcitems WHERE parts_id = $id|;
  128. ($form->{orphaned}) = $dbh->selectrow_array($query);
  129. $form->{orphaned} = !$form->{orphaned};
  130. $form->{orphaned} = 0 if $form->{project_id};
  131. if ($form->{item} eq 'assembly') {
  132. if ($form->{orphaned}) {
  133. $form->{orphaned} = !$form->{onhand};
  134. }
  135. }
  136. if ($form->{item} =~ /(part|service)/) {
  137. # get vendors
  138. $query = qq|
  139. SELECT v.id, v.name, pv.partnumber,
  140. pv.lastcost, pv.leadtime,
  141. pv.curr AS vendorcurr
  142. FROM partsvendor pv
  143. JOIN vendor v ON (v.id = pv.vendor_id)
  144. WHERE pv.parts_id = ?
  145. ORDER BY 2|;
  146. $sth = $dbh->prepare($query);
  147. $sth->execute($form->{id}) || $form->dberror($query);
  148. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  149. push @{ $form->{vendormatrix} }, $ref;
  150. }
  151. $sth->finish;
  152. }
  153. # get matrix
  154. if ($form->{item} ne 'labor') {
  155. $query = qq|
  156. SELECT pc.pricebreak, pc.sellprice AS customerprice,
  157. pc.curr AS customercurr, pc.validfrom,
  158. pc.validto, c.name, c.id AS cid,
  159. g.pricegroup, g.id AS gid
  160. FROM partscustomer pc
  161. LEFT JOIN customer c ON (c.id = pc.customer_id)
  162. LEFT JOIN pricegroup g ON (g.id = pc.pricegroup_id)
  163. WHERE pc.parts_id = ?
  164. ORDER BY c.name, g.pricegroup, pc.pricebreak|;
  165. $sth = $dbh->prepare($query);
  166. $sth->execute($form->{id}) || $form->dberror($query);
  167. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  168. push @{ $form->{customermatrix} }, $ref;
  169. }
  170. $sth->finish;
  171. }
  172. $form->run_custom_queries('parts', 'SELECT');
  173. }
  174. sub save {
  175. my ($self, $myconfig, $form) = @_;
  176. ($form->{inventory_accno}) = split(/--/, $form->{IC_inventory});
  177. ($form->{expense_accno}) = split(/--/, $form->{IC_expense});
  178. ($form->{income_accno}) = split(/--/, $form->{IC_income});
  179. my $dbh = $form->{dbh};
  180. # undo amount formatting
  181. for (qw(rop weight listprice sellprice lastcost stock)) {
  182. $form->{$_} = $form->parse_amount($myconfig, $form->{$_});
  183. }
  184. $form->{makemodel} = (($form->{make_1}) || ($form->{model_1})) ? 1 : 0;
  185. $form->{assembly} = ($form->{item} eq 'assembly') ? 1 : 0;
  186. for (qw(alternate obsolete onhand)) { $form->{$_} *= 1 }
  187. my $query;
  188. my $sth;
  189. my $i;
  190. my $null;
  191. my $vendor_id;
  192. my $customer_id;
  193. if ($form->{id}) {
  194. # get old price
  195. $query = qq|
  196. SELECT id, listprice, sellprice, lastcost, weight,
  197. project_id
  198. FROM parts
  199. WHERE id = ?|;
  200. my $sth = $dbh->prepare($query);
  201. $sth->execute($form->{id});
  202. my ($id, $listprice, $sellprice, $lastcost, $weight,
  203. $project_id)
  204. = $dbh->fetchrow_array();
  205. if ($id) {
  206. if (!$project_id) {
  207. # if item is part of an assembly
  208. # adjust all assemblies
  209. $query = qq|
  210. SELECT id, qty, adj
  211. FROM assembly
  212. WHERE parts_id = ?|;
  213. $sth = $dbh->prepare($query);
  214. $sth->execute($form->{id}) ||
  215. $form->dberror($query);
  216. while (my ($id, $qty, $adj)
  217. = $sth->fetchrow_array) {
  218. &update_assembly(
  219. $dbh, $form, $id, $qty, $adj,
  220. $listprice * 1, $sellprice * 1,
  221. $lastcost * 1, $weight * 1);
  222. }
  223. $sth->finish;
  224. }
  225. if ($form->{item} =~ /(part|service)/) {
  226. # delete partsvendor records
  227. $query = qq|
  228. DELETE FROM partsvendor
  229. WHERE parts_id = ?|;
  230. $sth = $dbh->prepare($query);
  231. $sth->execute($form->{id})
  232. || $form->dberror($query);
  233. }
  234. if ($form->{item} !~ /(service|labor)/) {
  235. # delete makemodel records
  236. $query = qq|
  237. DELETE FROM makemodel
  238. WHERE parts_id = ?|;
  239. $sth = $dbh->prepare($query);
  240. $sth->execute($form->{id})
  241. || $form->dberror($query);
  242. }
  243. if ($form->{item} eq 'assembly') {
  244. if ($form->{onhand}) {
  245. &adjust_inventory(
  246. $dbh, $form, $form->{id},
  247. $form->{onhand} * -1);
  248. }
  249. if ($form->{orphaned}) {
  250. # delete assembly records
  251. $query = qq|
  252. DELETE FROM assembly
  253. WHERE id = ?|;
  254. $sth = $dbh->prepare($query);
  255. $sth->execute($form->{id})
  256. || $form->dberror($query);
  257. } else {
  258. for $i (1 ..
  259. $form->{assembly_rows} - 1) {
  260. # update BOM, A only
  261. for (qw(bom adj)) {
  262. $form->{"${_}_$i"}
  263. *= 1;
  264. }
  265. $query = qq|
  266. UPDATE assembly
  267. SET bom = ?,
  268. adj = ?
  269. WHERE id = ?
  270. AND parts_id = ?|;
  271. $sth = $dbh->prepare($query);
  272. $sth->execute(
  273. $form->{"bom_$i"},
  274. $form->{"adj_$i"},
  275. $form->{id},
  276. $form->{"id_$i"}
  277. )|| $form->dberror(
  278. $query);
  279. }
  280. }
  281. $form->{onhand} += $form->{stock};
  282. }
  283. # delete tax records
  284. $query = qq|DELETE FROM partstax WHERE parts_id = ?|;
  285. $sth = $dbh->prepare($query);
  286. $sth->execute($form->{id})|| $form->dberror($query);
  287. # delete matrix
  288. $query = qq|
  289. DELETE FROM partscustomer
  290. WHERE parts_id = ?|;
  291. $sth = $dbh->prepare($query);
  292. $sth->execute($form->{id})|| $form->dberror($query);
  293. } else {
  294. $query = qq|INSERT INTO parts (id) VALUES (?)|;
  295. $sth = $dbh->prepare($query);
  296. $sth->execute($form->{id})|| $form->dberror($query);
  297. }
  298. }
  299. if (!$form->{id}) {
  300. my $uid = localtime;
  301. $uid .= "$$";
  302. $query = qq|INSERT INTO parts (partnumber) VALUES ('$uid')|;
  303. $dbh->do($query) || $form->dberror($query);
  304. $query = qq|SELECT id FROM parts WHERE partnumber = '$uid'|;
  305. $sth = $dbh->prepare($query);
  306. $sth->execute || $form->dberror($query);
  307. ($form->{id}) = $sth->fetchrow_array;
  308. $sth->finish;
  309. $form->{orphaned} = 1;
  310. $form->{onhand} = ($form->{stock} * 1)
  311. if $form->{item} eq 'assembly';
  312. }
  313. my $partsgroup_id;
  314. ($null, $partsgroup_id) = split /--/, $form->{partsgroup};
  315. $partsgroup_id *= 1;
  316. $form->{partnumber} = $form->update_defaults(
  317. $myconfig, "partnumber", $dbh) if ! $form->{partnumber};
  318. if (!$form->{priceupdate}){
  319. $form->{priceupdate} = 'now';
  320. }
  321. $query = qq|
  322. UPDATE parts
  323. SET partnumber = ?,
  324. description = ?,
  325. makemodel = ?,
  326. alternate = ?,
  327. assembly = ?,
  328. listprice = ?,
  329. sellprice = ?,
  330. lastcost = ?,
  331. weight = ?,
  332. priceupdate = ?,
  333. unit = ?,
  334. notes = ?,
  335. rop = ?,
  336. bin = ?,
  337. inventory_accno_id = (SELECT id FROM chart
  338. WHERE accno = ?),
  339. income_accno_id = (SELECT id FROM chart
  340. WHERE accno = ?),
  341. expense_accno_id = (SELECT id FROM chart
  342. WHERE accno = ?),
  343. obsolete = ?,
  344. image = ?,
  345. drawing = ?,
  346. microfiche = ?,
  347. partsgroup_id = ?
  348. WHERE id = ?|;
  349. $sth = $dbh->prepare($query);
  350. $sth->execute(
  351. $form->{partnumber}, $form->{description}, $form->{makemodel},
  352. $form->{alternate}, $form->{assembly}, $form->{listprice},
  353. $form->{sellprice}, $form->{lastcost}, $form->{weight},
  354. $form->{priceupdate}, $form->{unit}, $form->{notes},
  355. $form->{rop}, $form->{bin}, $form->{inventory_accno},
  356. $form->{income_accno}, $form->{expense_accno},
  357. $form->{obsolete}, $form->{image}, $form->{drawing},
  358. $form->{microfiche}, $partsgroup_id, $form->{id}
  359. ) || $form->dberror($query);
  360. # insert makemodel records
  361. if ($form->{item} =~ /(part|assembly)/) {
  362. $query = qq|
  363. INSERT INTO makemodel (parts_id, make, model)
  364. VALUES (?, ?, ?)|;
  365. $sth = $dbh->prepare($query) || $form->dberror($query);
  366. for $i (1 .. $form->{makemodel_rows}) {
  367. if (($form->{"make_$i"} ne "")
  368. || ($form->{"model_$i"} ne "")) {
  369. $sth->execute(
  370. $form->{id}, $form->{"make_$i"},
  371. $form->{"model_$i"}
  372. ) || $form->dberror($query);
  373. }
  374. }
  375. }
  376. # insert taxes
  377. $query = qq|
  378. INSERT INTO partstax (parts_id, chart_id)
  379. VALUES (?, (SELECT id FROM chart WHERE accno = ?))|;
  380. $sth = $dbh->prepare($query);
  381. for (split / /, $form->{taxaccounts}) {
  382. if ($form->{"IC_tax_$_"}) {
  383. $sth->execute($form->{id}, $_)
  384. || $form->dberror($query);
  385. }
  386. }
  387. @a = localtime;
  388. $a[5] += 1900;
  389. $a[4]++;
  390. $a[4] = substr("0$a[4]", -2);
  391. $a[3] = substr("0$a[3]", -2);
  392. my $shippingdate = "$a[5]$a[4]$a[3]";
  393. ($form->{employee}, $form->{employee_id}) = $form->get_employee($dbh);
  394. # add assembly records
  395. if ($form->{item} eq 'assembly' && !$project_id) {
  396. if ($form->{orphaned}) {
  397. $query = qq|
  398. INSERT INTO assembly
  399. (id, parts_id, qty, bom, adj)
  400. VALUES (?, ?, ?, ?, ?)|;
  401. $sth = $dbh->prepare($query);
  402. for $i (1 .. $form->{assembly_rows}) {
  403. $form->{"qty_$i"} = $form->parse_amount(
  404. $myconfig, $form->{"qty_$i"});
  405. $sth->execute(
  406. $form->{id}, $form->{"id_$i"},
  407. $form->{"qty_$i"}, $form->{"bom_$i"},
  408. $form->{"adj_$i"}
  409. ) || $form->dberror($query);
  410. }
  411. }
  412. # adjust onhand for the parts
  413. if ($form->{onhand}) {
  414. &adjust_inventory(
  415. $dbh, $form, $form->{id}, $form->{onhand});
  416. }
  417. }
  418. # add vendors
  419. if ($form->{item} ne 'assembly') {
  420. $updparts{$form->{id}} = 1;
  421. for $i (1 .. $form->{vendor_rows}) {
  422. if (($form->{"vendor_$i"} ne "")
  423. && $form->{"lastcost_$i"}) {
  424. ($null, $vendor_id)
  425. = split /--/, $form->{"vendor_$i"};
  426. for (qw(lastcost leadtime)) {
  427. $form->{"${_}_$i"}
  428. = $form->parse_amount(
  429. $myconfig,
  430. $form->{"${_}_$i"});
  431. }
  432. $query = qq|
  433. INSERT INTO partsvendor
  434. (vendor_id, parts_id,
  435. partnumber, lastcost,
  436. leadtime, curr)
  437. VALUES (?, ?, ?, ?, ?, ?)|;
  438. $sth = $dbh->prepare($query);
  439. $sth->execute(
  440. $vendor_id, $form->{id},
  441. $form->{"partnumber_$i"},
  442. $form->{"lastcost_$i"},
  443. $form->{"leadtime_$i"},
  444. $form->{"vendorcurr_$i"}
  445. )|| $form->dberror($query);
  446. }
  447. }
  448. }
  449. # add pricematrix
  450. for $i (1 .. $form->{customer_rows}) {
  451. for (qw(pricebreak customerprice)) {
  452. $form->{"${_}_$i"} = $form->parse_amount(
  453. $myconfig, $form->{"${_}_$i"});
  454. }
  455. if ($form->{"customerprice_$i"}) {
  456. ($null, $customer_id)
  457. = split /--/, $form->{"customer_$i"};
  458. $customer_id *= 1;
  459. ($null, $pricegroup_id)
  460. = split /--/, $form->{"pricegroup_$i"};
  461. $query = qq|
  462. INSERT INTO partscustomer
  463. (parts_id, customer_id,
  464. pricegroup_id, pricebreak,
  465. sellprice, curr,
  466. validfrom, validto)
  467. VALUES (?, ?, ?, ?, ?, ?, ?, ?)|;
  468. $sth = $dbh->prepare($query);
  469. $sth->execute(
  470. $form->{id}, $customer_id, $pricegroup_id,
  471. $form->{"pricebreak_$i"},
  472. $form->{"customerprice_$i"},
  473. $form->{"customercurr_$i"},
  474. $form->{"validfrom_$i"}, $form->{"validto_$i"}
  475. )|| $form->dberror($query);
  476. }
  477. }
  478. my $rc = $dbh->commit;
  479. $form->run_custom_queries('parts', 'UPDATE');
  480. $rc;
  481. }
  482. sub update_assembly {
  483. my ($dbh, $form, $id, $qty, $adj, $listprice, $sellprice, $lastcost,
  484. $weight) = @_;
  485. my $formlistprice = $form->{listprice};
  486. my $formsellprice = $form->{sellprice};
  487. if (!$adj) {
  488. $formlistprice = $listprice;
  489. $formsellprice = $sellprice;
  490. }
  491. my $query = qq|SELECT id, qty, adj FROM assembly WHERE parts_id = ?|;
  492. my $sth = $dbh->prepare($query);
  493. $sth->execute($id) || $form->dberror($query);
  494. $form->{$id} = 1; # Not sure what this is for...
  495. # In fact, we don't seem to use it... Chris T
  496. while (my ($pid, $aqty, $aadj) = $sth->fetchrow_array) {
  497. &update_assembly($dbh, $form, $pid, $aqty * $qty, $aadj,
  498. $listprice, $sellprice, $lastcost, $weight)
  499. if !$form->{$pid};
  500. }
  501. $sth->finish;
  502. $qty = $dbh->quote($qty);
  503. $formlistprice = $dbh->quote($formlistprice );
  504. $listprice = $dbh->quote($listprice );
  505. $formsellprice = $dbh->quote($formsellprice );
  506. $formlastcost = $dbh->quote($form->{lastcost});
  507. $lastcost = $dbh->quote($lastcost);
  508. $weight = $dbh->quote($weight);
  509. $id = $dbh->quote($id);
  510. $query = qq|
  511. UPDATE parts
  512. SET listprice = listprice +
  513. $qty * ($formlistprice - $listprice),
  514. sellprice = sellprice +
  515. $qty * ($formsellprice - $sellprice),
  516. lastcost = lastcost +
  517. $qty * ($form->{lastcost} - $lastcost),
  518. weight = weight +
  519. $qty * ($form->{weight} - $weight)
  520. WHERE id = $id|;
  521. $dbh->do($query) || $form->dberror($query);
  522. delete $form->{$id};
  523. }
  524. sub retrieve_assemblies {
  525. my ($self, $myconfig, $form) = @_;
  526. # connect to database
  527. my $dbh = $form->{dbh};
  528. my $where = '1 = 1';
  529. if ($form->{partnumber} ne "") {
  530. my $partnumber = $dbh->quote($form->like(
  531. lc $form->{partnumber}));
  532. $where .= " AND lower(p.partnumber) LIKE $partnumber";
  533. }
  534. if ($form->{description} ne "") {
  535. my $description = $dbh->($form->like(lc $form->{description}));
  536. $where .= " AND lower(p.description) LIKE $description";
  537. }
  538. $where .= qq| AND p.obsolete = '0'
  539. AND p.project_id IS NULL|;
  540. my %ordinal = (
  541. 'partnumber' => 2,
  542. 'description' => 3,
  543. 'bin' => 4
  544. );
  545. my @a = qw(partnumber description bin);
  546. my $sortorder = $form->sort_order(\@a, \%ordinal);
  547. # retrieve assembly items
  548. my $query = qq|
  549. SELECT p.id, p.partnumber, p.description, p.bin, p.onhand,
  550. p.rop
  551. FROM parts p
  552. WHERE $where
  553. AND p.assembly = '1'
  554. ORDER BY $sortorder|;
  555. my $sth = $dbh->prepare($query);
  556. $sth->execute || $form->dberror($query);
  557. $query = qq|
  558. SELECT sum(p.inventory_accno_id), p.assembly
  559. FROM parts p
  560. JOIN assembly a ON (a.parts_id = p.id)
  561. WHERE a.id = ?
  562. GROUP BY p.assembly|;
  563. my $svh = $dbh->prepare($query) || $form->dberror($query);
  564. my $inh;
  565. if ($form->{checkinventory}) {
  566. $query = qq|
  567. SELECT p.id, p.onhand, a.qty
  568. FROM parts p
  569. JOIN assembly a ON (a.parts_id = p.id)
  570. WHERE (p.inventory_accno_id > 0 OR p.assembly)
  571. AND p.income_accno_id > 0 AND a.id = ?|;
  572. $inh = $dbh->prepare($query) || $form->dberror($query);
  573. }
  574. my %available = ();
  575. my %required;
  576. my $ref;
  577. my $aref;
  578. my $stock;
  579. my $howmany;
  580. my $ok;
  581. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  582. $svh->execute($ref->{id});
  583. ($ref->{inventory}, $ref->{assembly}) = $svh->fetchrow_array;
  584. $svh->finish;
  585. if ($ref->{inventory} || $ref->{assembly}) {
  586. $ok = 1;
  587. if ($form->{checkinventory}) {
  588. $inh->execute($ref->{id})
  589. || $form->dberror($query);;
  590. $ok = 0;
  591. %required = ();
  592. while ($aref
  593. = $inh->fetchrow_hashref(NAME_lc)) {
  594. $available{$aref->{id}} =
  595. (exists $available{$aref->{id}})
  596. ? $available{$aref->{id}}
  597. : $aref->{onhand};
  598. $required{$aref->{id}} = $aref->{qty};
  599. if ($available{$aref->{id}}
  600. >= $aref->{qty}) {
  601. $howmany =
  602. ($aref->{qty})
  603. ? int $available{
  604. $aref->{id}}
  605. /$aref->{qty}
  606. : 1;
  607. if ($stock) {
  608. $stock =
  609. ($stock
  610. > $howmany)
  611. ? $howmany
  612. : $stock;
  613. } else {
  614. $stock = $howmany;
  615. }
  616. $ok = 1;
  617. $available{$aref->{id}}
  618. -= $aref->{qty}
  619. * $stock;
  620. } else {
  621. $ok = 0;
  622. for (keys %required) {
  623. $available{$_} +=
  624. $required{$_}
  625. * $stock;
  626. }
  627. $stock = 0;
  628. last;
  629. }
  630. }
  631. $inh->finish;
  632. $ref->{stock} = $stock;
  633. }
  634. push @{ $form->{assembly_items} }, $ref if $ok;
  635. }
  636. }
  637. $sth->finish;
  638. $dbh->commit;
  639. }
  640. sub restock_assemblies {
  641. my ($self, $myconfig, $form) = @_;
  642. # connect to database
  643. my $dbh = $form->{dbh};
  644. for my $i (1 .. $form->{rowcount}) {
  645. $form->{"qty_$i"} = $form->parse_amount(
  646. $myconfig, $form->{"qty_$i"});
  647. if ($form->{"qty_$i"}) {
  648. &adjust_inventory(
  649. $dbh, $form, $form->{"id_$i"},
  650. $form->{"qty_$i"});
  651. }
  652. }
  653. my $rc = $dbh->commit;
  654. $rc;
  655. }
  656. sub adjust_inventory {
  657. # Private method. Do not commit transaction at end of function...
  658. my ($dbh, $form, $id, $qty) = @_;
  659. my $query = qq|
  660. SELECT p.id, p.inventory_accno_id, p.assembly, a.qty
  661. FROM parts p
  662. JOIN assembly a ON (a.parts_id = p.id)
  663. WHERE a.id = ?|;
  664. my $sth = $dbh->prepare($query);
  665. $sth->execute($id) || $form->dberror($query);
  666. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  667. # is it a service item then loop
  668. if (! $ref->{inventory_accno_id}) {
  669. next if ! $ref->{assembly};
  670. }
  671. # adjust parts onhand
  672. $form->update_balance(
  673. $dbh, "parts", "onhand", qq|id = $ref->{id}|,
  674. $qty * $ref->{qty} * -1);
  675. }
  676. $sth->finish;
  677. # update assembly
  678. $form->update_balance($dbh, "parts", "onhand", qq|id = $id|, $qty);
  679. }
  680. sub delete {
  681. my ($self, $myconfig, $form) = @_;
  682. my $dbh = $form->{dbh};
  683. my $query;
  684. $query = qq|DELETE FROM parts WHERE id = ?|;
  685. $sth = $dbh->prepare($query);
  686. $sth->execute($form->{id}) || $form->dberror($query);
  687. $query = qq|DELETE FROM partstax WHERE parts_id = ?|;
  688. $sth = $dbh->prepare($query);
  689. $sth->execute($form->{id}) || $form->dberror($query);
  690. if ($form->{item} ne 'assembly') {
  691. $query = qq|DELETE FROM partsvendor WHERE parts_id = ?|;
  692. $sth = $dbh->prepare($query);
  693. $sth->execute($form->{id}) || $form->dberror($query);
  694. }
  695. # check if it is a part, assembly or service
  696. if ($form->{item} ne 'service') {
  697. $query = qq|DELETE FROM makemodel WHERE parts_id = ?|;
  698. $sth = $dbh->prepare($query);
  699. $sth->execute($form->{id}) || $form->dberror($query);
  700. }
  701. if ($form->{item} eq 'assembly') {
  702. $query = qq|DELETE FROM assembly WHERE id = ?|;
  703. $sth = $dbh->prepare($query);
  704. $sth->execute($form->{id}) || $form->dberror($query);
  705. }
  706. $query = qq|DELETE FROM inventory WHERE parts_id = ?|;
  707. $sth = $dbh->prepare($query);
  708. $sth->execute($form->{id}) || $form->dberror($query);
  709. $query = qq|DELETE FROM partscustomer WHERE parts_id = ?|;
  710. $sth = $dbh->prepare($query);
  711. $sth->execute($form->{id}) || $form->dberror($query);
  712. $query = qq|DELETE FROM translation WHERE trans_id = ?|;
  713. $sth = $dbh->prepare($query);
  714. $sth->execute($form->{id}) || $form->dberror($query);
  715. # commit
  716. my $rc = $dbh->commit;
  717. $rc;
  718. }
  719. sub assembly_item {
  720. my ($self, $myconfig, $form) = @_;
  721. my $dbh = $form->{dbh};
  722. my $i = $form->{assembly_rows};
  723. my $var;
  724. my $null;
  725. my $where = "p.obsolete = '0'";
  726. if ($form->{"partnumber_$i"} ne "") {
  727. $var = $dbh->quote($form->like(lc $form->{"partnumber_$i"}));
  728. $where .= " AND lower(p.partnumber) LIKE $var";
  729. }
  730. if ($form->{"description_$i"} ne "") {
  731. $var = $dbh->quote($form->like(lc $form->{"description_$i"}));
  732. $where .= " AND lower(p.description) LIKE $var";
  733. }
  734. if ($form->{"partsgroup_$i"} ne "") {
  735. ($null, $var) = split /--/, $form->{"partsgroup_$i"};
  736. $var = $dbh->quote($var);
  737. $where .= qq| AND p.partsgroup_id = $var|;
  738. }
  739. if ($form->{id}) {
  740. $where .= " AND p.id != ".$dbh->quote($form->{id});
  741. }
  742. if ($form->{"description_$i"} ne "") {
  743. $where .= " ORDER BY p.description";
  744. } else {
  745. $where .= " ORDER BY p.partnumber";
  746. }
  747. my $query = qq|
  748. SELECT p.id, p.partnumber, p.description, p.sellprice,
  749. p.weight, p.onhand, p.unit, p.lastcost,
  750. pg.partsgroup, p.partsgroup_id
  751. FROM parts p
  752. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  753. WHERE $where|;
  754. my $sth = $dbh->prepare($query);
  755. $sth->execute || $form->dberror($query);
  756. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  757. push @{ $form->{item_list} }, $ref;
  758. }
  759. $sth->finish;
  760. }
  761. sub all_parts {
  762. my ($self, $myconfig, $form) = @_;
  763. $dbh = $form->{dbh};
  764. my $where = '1 = 1';
  765. my $null;
  766. my $var;
  767. my $ref;
  768. for (qw(partnumber drawing microfiche)) {
  769. if ($form->{$_} ne "") {
  770. $var = $dbh->quote($form->like(lc $form->{$_}));
  771. $where .= " AND lower(p.$_) LIKE $var";
  772. }
  773. }
  774. # special case for description
  775. if ($form->{description} ne "") {
  776. unless ($form->{bought} || $form->{sold} || $form->{onorder}
  777. || $form->{ordered} || $form->{rfq} || $form->{quoted}
  778. ) {
  779. $var = $dbh->quote($form->like(
  780. lc $form->{description}));
  781. $where .= " AND lower(p.description) LIKE $var";
  782. }
  783. }
  784. # assembly components
  785. my $assemblyflds;
  786. if ($form->{searchitems} eq 'component') {
  787. $assemblyflds = qq|, p1.partnumber AS assemblypartnumber,
  788. a.id AS assembly_id|;
  789. }
  790. # special case for serialnumber
  791. if ($form->{l_serialnumber}) {
  792. if ($form->{serialnumber} ne "") {
  793. $var = $dbh->quote(
  794. $form->like(lc $form->{serialnumber}));
  795. $where .= " AND lower(i.serialnumber) LIKE $var";
  796. }
  797. }
  798. if (($form->{warehouse} ne "") || $form->{l_warehouse}) {
  799. $form->{l_warehouse} = 1;
  800. }
  801. if ($form->{searchitems} eq 'part') {
  802. $where .= " AND p.inventory_accno_id > 0 AND p.income_accno_id > 0";
  803. }
  804. if ($form->{searchitems} eq 'assembly') {
  805. $form->{bought} = "";
  806. $where .= " AND p.assembly = '1'";
  807. }
  808. if ($form->{searchitems} eq 'service') {
  809. $where .= " AND p.assembly = '0' AND p.inventory_accno_id IS NULL";
  810. }
  811. if ($form->{searchitems} eq 'labor') {
  812. $where .= " AND p.inventory_accno_id > 0 AND p.income_accno_id IS NULL";
  813. }
  814. # items which were never bought, sold or on an order
  815. if ($form->{itemstatus} eq 'orphaned') {
  816. $where .= qq|
  817. AND p.onhand = 0
  818. AND p.id NOT IN (SELECT p.id FROM parts p
  819. JOIN invoice i
  820. ON (p.id = i.parts_id))
  821. AND p.id NOT IN (SELECT p.id FROM parts p
  822. JOIN assembly a
  823. ON (p.id = a.parts_id))
  824. AND p.id NOT IN (SELECT p.id FROM parts p
  825. JOIN orderitems o
  826. ON (p.id = o.parts_id))
  827. AND p.id NOT IN (SELECT p.id FROM parts p
  828. JOIN jcitems j
  829. ON (p.id = j.parts_id))|;
  830. }
  831. if ($form->{itemstatus} eq 'active') {
  832. $where .= " AND p.obsolete = '0'";
  833. }
  834. if ($form->{itemstatus} eq 'obsolete') {
  835. $where .= " AND p.obsolete = '1'";
  836. }
  837. if ($form->{itemstatus} eq 'onhand') {
  838. $where .= " AND p.onhand > 0";
  839. }
  840. if ($form->{itemstatus} eq 'short') {
  841. $where .= " AND p.onhand < p.rop";
  842. }
  843. my $makemodelflds = qq|, '', ''|;;
  844. my $makemodeljoin;
  845. if (($form->{make} ne "") || $form->{l_make} || ($form->{model} ne "")
  846. || $form->{l_model}) {
  847. $makemodelflds = qq|, m.make, m.model|;
  848. $makemodeljoin = qq|LEFT JOIN makemodel m ON (m.parts_id = p.id)|;
  849. if ($form->{make} ne "") {
  850. $var = $dbh->quote($form->like(lc $form->{make}));
  851. $where .= " AND lower(m.make) LIKE $var";
  852. }
  853. if ($form->{model} ne "") {
  854. $var = $dbh->quote($form->like(lc $form->{model}));
  855. $where .= " AND lower(m.model) LIKE $var";
  856. }
  857. }
  858. if ($form->{partsgroup} ne "") {
  859. ($null, $var) = split /--/, $form->{partsgroup};
  860. $where .= qq| AND p.partsgroup_id = | . $dbh->quote($var);
  861. }
  862. my %ordinal = (
  863. 'partnumber' => 2,
  864. 'description' => 3,
  865. 'bin' => 6,
  866. 'priceupdate' => 13,
  867. 'drawing' => 15,
  868. 'microfiche' => 16,
  869. 'partsgroup' => 18,
  870. 'make' => 21,
  871. 'model' => 22,
  872. 'assemblypartnumber' => 23
  873. );
  874. my @a = qw(partnumber description);
  875. my $sortorder = $form->sort_order(\@a, \%ordinal);
  876. my $query = qq|SELECT value FROM defaults WHERE setting_key = 'curr'|;
  877. my ($curr) = $dbh->selectrow_array($query);
  878. $curr =~ s/:.*//;
  879. $curr = $dbh->quote($curr);
  880. my $flds = qq|
  881. p.id, p.partnumber, p.description, p.onhand, p.unit,
  882. p.bin, p.sellprice, p.listprice, p.lastcost, p.rop,
  883. p.avgcost,
  884. p.weight, p.priceupdate, p.image, p.drawing, p.microfiche,
  885. p.assembly, pg.partsgroup, $curr AS curr,
  886. c1.accno AS inventory, c2.accno AS income, c3.accno AS expense,
  887. p.notes
  888. $makemodelflds $assemblyflds
  889. |;
  890. $query = qq|
  891. SELECT $flds
  892. FROM parts p
  893. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  894. LEFT JOIN chart c1 ON (c1.id = p.inventory_accno_id)
  895. LEFT JOIN chart c2 ON (c2.id = p.income_accno_id)
  896. LEFT JOIN chart c3 ON (c3.id = p.expense_accno_id)
  897. $makemodeljoin
  898. WHERE $where
  899. ORDER BY $sortorder|;
  900. # redo query for components report
  901. if ($form->{searchitems} eq 'component') {
  902. $flds =~ s/p.onhand/a.qty AS onhand/;
  903. $query = qq|
  904. SELECT $flds
  905. FROM assembly a
  906. JOIN parts p ON (a.parts_id = p.id)
  907. JOIN parts p1 ON (a.id = p1.id)
  908. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  909. LEFT JOIN chart c1 ON (c1.id = p.inventory_accno_id)
  910. LEFT JOIN chart c2 ON (c2.id = p.income_accno_id)
  911. LEFT JOIN chart c3 ON (c3.id = p.expense_accno_id)
  912. $makemodeljoin
  913. WHERE $where
  914. ORDER BY $sortorder|;
  915. }
  916. # rebuild query for bought and sold items
  917. if ($form->{bought} || $form->{sold} || $form->{onorder}
  918. || $form->{ordered} || $form->{rfq} || $form->{quoted}
  919. ) {
  920. $form->sort_order();
  921. @a = qw(partnumber description curr employee name
  922. serialnumber id);
  923. push @a, "invnumber" if ($form->{bought} || $form->{sold});
  924. push @a, "ordnumber" if ($form->{onorder} || $form->{ordered});
  925. push @a, "quonumber" if ($form->{rfq} || $form->{quoted});
  926. %ordinal = (
  927. 'partnumber' => 2,
  928. 'description' => 3,
  929. 'serialnumber' => 4,
  930. 'bin' => 7,
  931. 'priceupdate' => 14,
  932. 'partsgroup' => 19,
  933. 'invnumber' => 20,
  934. 'ordnumber' => 21,
  935. 'quonumber' => 22,
  936. 'name' => 24,
  937. 'employee' => 25,
  938. 'curr' => 26,
  939. 'make' => 29,
  940. 'model' => 30
  941. );
  942. $sortorder = $form->sort_order(\@a, \%ordinal);
  943. my $union = "";
  944. $query = "";
  945. if ($form->{bought} || $form->{sold}) {
  946. my $invwhere = "$where";
  947. my $transdate =
  948. ($form->{method} eq 'accrual')
  949. ? "transdate"
  950. : "datepaid";
  951. $invwhere .= " AND i.assemblyitem = '0'";
  952. $invwhere .= " AND a.$transdate >= " .
  953. $dbh->quote($form->{transdatefrom})
  954. if $form->{transdatefrom};
  955. $invwhere .= " AND a.$transdate <= " .
  956. $dbh->quote($form->{transdateto})
  957. if $form->{transdateto};
  958. if ($form->{description} ne "") {
  959. $var = dbh->quote(
  960. $form->like(lc $form->{description}));
  961. $invwhere .=
  962. " AND lower(i.description) LIKE $var";
  963. }
  964. if ($form->{open} || $form->{closed}) {
  965. if ($form->{open} && $form->{closed}) {
  966. if ($form->{method} eq 'cash') {
  967. $invwhere .=
  968. " AND a.amount = a.paid";
  969. }
  970. } else {
  971. if ($form->{open}) {
  972. if ($form->{method} eq 'cash') {
  973. $invwhere .=
  974. " AND a.id = 0";
  975. } else {
  976. $invwhere .=
  977. " AND NOT a.amount = a.paid";
  978. }
  979. } else {
  980. $invwhere .=
  981. " AND a.amount = a.paid";
  982. }
  983. }
  984. } else {
  985. $invwhere .= " AND a.id = 0";
  986. }
  987. my $flds = qq|
  988. p.id, p.partnumber, i.description,
  989. i.serialnumber, i.qty AS onhand, i.unit, p.bin,
  990. i.sellprice, p.listprice, p.lastcost, p.rop,
  991. p.weight, p.avgcost, p.priceupdate, p.image,
  992. p.drawing, p.microfiche, p.assembly,
  993. pg.partsgroup, a.invnumber, a.ordnumber,
  994. a.quonumber, i.trans_id, ct.name,
  995. e.name AS employee, a.curr, a.till, p.notes
  996. $makemodelfld|;
  997. if ($form->{bought}) {
  998. my $rflds = $flds;
  999. $rflds =~
  1000. s/i.qty AS onhand/i.qty * -1 AS onhand/;
  1001. $query = qq|
  1002. SELECT $rflds, 'ir' AS module,
  1003. '' AS type,
  1004. (SELECT sell
  1005. FROM exchangerate ex
  1006. WHERE ex.curr = a.curr
  1007. AND ex.transdate
  1008. = a.$transdate)
  1009. AS exchangerate, i.discount
  1010. FROM invoice i
  1011. JOIN parts p
  1012. ON (p.id = i.parts_id)
  1013. JOIN ap a ON (a.id = i.trans_id)
  1014. JOIN vendor ct
  1015. ON (a.vendor_id = ct.id)
  1016. LEFT JOIN partsgroup pg
  1017. ON (p.partsgroup_id = pg.id)
  1018. LEFT JOIN employee e
  1019. ON (a.employee_id = e.id)
  1020. $makemodeljoin
  1021. WHERE $invwhere|;
  1022. $union = "
  1023. UNION ALL";
  1024. }
  1025. if ($form->{sold}) {
  1026. $query .= qq|
  1027. $union
  1028. SELECT $flds, 'is' AS module,
  1029. '' AS type,
  1030. (SELECT buy
  1031. FROM exchangerate ex
  1032. WHERE ex.curr = a.curr
  1033. AND ex.transdate
  1034. = a.$transdate)
  1035. AS exchangerate, i.discount
  1036. FROM invoice i
  1037. JOIN parts p
  1038. ON (p.id = i.parts_id)
  1039. JOIN ar a ON (a.id = i.trans_id)
  1040. JOIN customer ct
  1041. ON (a.customer_id = ct.id)
  1042. LEFT JOIN partsgroup pg
  1043. ON (p.partsgroup_id = pg.id)
  1044. LEFT JOIN employee e
  1045. ON (a.employee_id = e.id)
  1046. $makemodeljoin
  1047. WHERE $invwhere|;
  1048. $union = "
  1049. UNION ALL";
  1050. }
  1051. }
  1052. if ($form->{onorder} || $form->{ordered}) {
  1053. my $ordwhere = "$where
  1054. AND a.quotation = '0'";
  1055. $ordwhere .= " AND a.transdate >= ".
  1056. $dbh->quote($form->{transdatefrom})
  1057. if $form->{transdatefrom};
  1058. $ordwhere .= " AND a.transdate <= ".
  1059. $dbh->quote($form->{transdateto})
  1060. if $form->{transdateto};
  1061. if ($form->{description} ne "") {
  1062. $var = $dbh->quote(
  1063. $form->like(lc $form->{description}));
  1064. $ordwhere .= " AND lower(i.description) LIKE $var";
  1065. }
  1066. if ($form->{open} || $form->{closed}) {
  1067. unless ($form->{open} && $form->{closed}) {
  1068. $ordwhere .= " AND a.closed = '0'"
  1069. if $form->{open};
  1070. $ordwhere .= " AND a.closed = '1'"
  1071. if $form->{closed};
  1072. }
  1073. } else {
  1074. $ordwhere .= " AND a.id = 0";
  1075. }
  1076. $flds = qq|
  1077. p.id, p.partnumber, i.description,
  1078. i.serialnumber, i.qty AS onhand, i.unit, p.bin,
  1079. i.sellprice, p.listprice, p.lastcost, p.rop,
  1080. p.weight, p.avgcost, p.priceupdate, p.image,
  1081. p.drawing, p.microfiche, p.assembly,
  1082. pg.partsgroup, '' AS invnumber, a.ordnumber,
  1083. a.quonumber, i.trans_id, ct.name,
  1084. e.name AS employee, a.curr, '0' AS till,
  1085. p.notes
  1086. $makemodelfld|;
  1087. if ($form->{ordered}) {
  1088. $query .= qq|
  1089. $union
  1090. SELECT $flds, 'oe' AS module,
  1091. 'sales_order' AS type,
  1092. (SELECT buy
  1093. FROM exchangerate ex
  1094. WHERE ex.curr = a.curr
  1095. AND ex.transdate
  1096. = a.transdate)
  1097. AS exchangerate, i.discount
  1098. FROM orderitems i
  1099. JOIN parts p ON (i.parts_id = p.id)
  1100. JOIN oe a ON (i.trans_id = a.id)
  1101. JOIN customer ct
  1102. ON (a.customer_id = ct.id)
  1103. LEFT JOIN partsgroup pg
  1104. ON (p.partsgroup_id = pg.id)
  1105. LEFT JOIN employee e
  1106. ON (a.employee_id = e.id)
  1107. $makemodeljoin
  1108. WHERE $ordwhere
  1109. AND a.customer_id > 0|;
  1110. $union = "
  1111. UNION ALL";
  1112. }
  1113. if ($form->{onorder}) {
  1114. $flds = qq|
  1115. p.id, p.partnumber, i.description,
  1116. i.serialnumber, i.qty AS onhand, i.unit,
  1117. p.bin, i.sellprice, p.listprice,
  1118. p.lastcost, p.rop, p.weight, p.avgcost,
  1119. p.priceupdate, p.image, p.drawing,
  1120. p.microfiche, p.assembly,
  1121. pg.partsgroup, '' AS invnumber,
  1122. a.ordnumber, a.quonumber,
  1123. i.trans_id, ct.name,e.name AS employee,
  1124. a.curr, '0' AS till, p.notes
  1125. $makemodelfld|;
  1126. $query .= qq|
  1127. $union
  1128. SELECT $flds, 'oe' AS module,
  1129. 'purchase_order' AS type,
  1130. (SELECT sell
  1131. FROM exchangerate ex
  1132. WHERE ex.curr = a.curr
  1133. AND ex.transdate
  1134. = a.transdate)
  1135. AS exchangerate, i.discount
  1136. FROM orderitems i
  1137. JOIN parts p ON (i.parts_id = p.id)
  1138. JOIN oe a ON (i.trans_id = a.id)
  1139. JOIN vendor ct
  1140. ON (a.vendor_id = ct.id)
  1141. LEFT JOIN partsgroup pg
  1142. ON (p.partsgroup_id = pg.id)
  1143. LEFT JOIN employee e
  1144. ON (a.employee_id = e.id)
  1145. $makemodeljoin
  1146. WHERE $ordwhere
  1147. AND a.vendor_id > 0|;
  1148. }
  1149. }
  1150. if ($form->{rfq} || $form->{quoted}) {
  1151. my $quowhere = "$where
  1152. AND a.quotation = '1'";
  1153. $quowhere .= " AND a.transdate >= ".
  1154. $dbh->quote($form->{transdatefrom})
  1155. if $form->{transdatefrom};
  1156. $quowhere .= " AND a.transdate <= ".
  1157. $dbh->quote($form->{transdateto})
  1158. if $form->{transdateto};
  1159. if ($form->{description} ne "") {
  1160. $var = $dbh->quote(
  1161. $form->like(lc $form->{description}));
  1162. $quowhere .= " AND lower(i.description) LIKE $var";
  1163. }
  1164. if ($form->{open} || $form->{closed}) {
  1165. unless ($form->{open} && $form->{closed}) {
  1166. $ordwhere .= " AND a.closed = '0'"
  1167. if $form->{open};
  1168. $ordwhere .= " AND a.closed = '1'"
  1169. if $form->{closed};
  1170. }
  1171. } else {
  1172. $ordwhere .= " AND a.id = 0";
  1173. }
  1174. $flds = qq|
  1175. p.id, p.partnumber, i.description,
  1176. i.serialnumber, i.qty AS onhand, i.unit, p.bin,
  1177. i.sellprice, p.listprice, p.lastcost, p.rop,
  1178. p.weight, p.avgcost, p.priceupdate, p.image,
  1179. p.drawing, p.microfiche, p.assembly,
  1180. pg.partsgroup, '' AS invnumber, a.ordnumber,
  1181. a.quonumber, i.trans_id, ct.name,
  1182. e.name AS employee, a.curr, '0' AS till, p.notes
  1183. $makemodelfld|;
  1184. if ($form->{quoted}) {
  1185. $query .= qq|
  1186. $union
  1187. SELECT $flds, 'oe' AS module,
  1188. 'sales_quotation' AS type,
  1189. (SELECT buy
  1190. FROM exchangerate ex
  1191. WHERE ex.curr = a.curr
  1192. AND ex.transdate
  1193. = a.transdate)
  1194. AS exchangerate,
  1195. i.discount
  1196. FROM orderitems i
  1197. JOIN parts p ON (i.parts_id = p.id)
  1198. JOIN oe a ON (i.trans_id = a.id)
  1199. JOIN customer ct
  1200. ON (a.customer_id = ct.id)
  1201. LEFT JOIN partsgroup pg
  1202. ON (p.partsgroup_id = pg.id)
  1203. LEFT JOIN employee e
  1204. ON (a.employee_id = e.id)
  1205. $makemodeljoin
  1206. WHERE $quowhere
  1207. AND a.customer_id > 0|;
  1208. $union = "
  1209. UNION ALL";
  1210. }
  1211. if ($form->{rfq}) {
  1212. $flds = qq|
  1213. p.id, p.partnumber, i.description,
  1214. i.serialnumber, i.qty AS onhand,
  1215. i.unit, p.bin, i.sellprice, p.listprice,
  1216. p.lastcost, p.rop, p.weight, p.avgcost,
  1217. p.priceupdate, p.image, p.drawing,
  1218. p.microfiche, p.assembly,
  1219. pg.partsgroup, '' AS invnumber,
  1220. a.ordnumber, a.quonumber,
  1221. i.trans_id, ct.name, e.name AS employee,
  1222. a.curr, '0' AS till, p.notes
  1223. $makemodelfld|;
  1224. $query .= qq|
  1225. $union
  1226. SELECT $flds, 'oe' AS module,
  1227. 'request_quotation' AS type,
  1228. (SELECT sell
  1229. FROM exchangerate ex
  1230. WHERE ex.curr = a.curr
  1231. AND ex.transdate
  1232. = a.transdate)
  1233. AS exchangerate, i.discount
  1234. FROM orderitems i
  1235. JOIN parts p ON (i.parts_id = p.id)
  1236. JOIN oe a ON (i.trans_id = a.id)
  1237. JOIN vendor ct
  1238. ON (a.vendor_id = ct.id)
  1239. LEFT JOIN partsgroup pg
  1240. ON (p.partsgroup_id = pg.id)
  1241. LEFT JOIN employee e
  1242. ON (a.employee_id = e.id)
  1243. $makemodeljoin
  1244. WHERE $quowhere
  1245. AND a.vendor_id > 0|;
  1246. }
  1247. }
  1248. $query .= qq|
  1249. ORDER BY $sortorder|;
  1250. }
  1251. my $sth = $dbh->prepare($query);
  1252. $sth->execute || $form->dberror($query);
  1253. $query = qq|
  1254. SELECT c.accno
  1255. FROM chart c
  1256. JOIN partstax pt ON (pt.chart_id = c.id)
  1257. WHERE pt.parts_id = ?
  1258. ORDER BY accno|;
  1259. my $pth = $dbh->prepare($query) || $form->dberror($query);
  1260. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1261. $pth->execute($ref->{id});
  1262. while (($accno) = $pth->fetchrow_array) {
  1263. $ref->{tax} .= "$accno ";
  1264. }
  1265. $pth->finish;
  1266. push @{ $form->{parts} }, $ref;
  1267. }
  1268. $sth->finish;
  1269. @a = ();
  1270. # include individual items for assembly
  1271. if (($form->{searchitems} eq 'assembly') && $form->{individual}) {
  1272. if ($form->{sold} || $form->{ordered} || $form->{quoted}) {
  1273. $flds = qq|
  1274. p.id, p.partnumber, p.description,
  1275. p.onhand AS perassembly, p.unit, p.bin,
  1276. p.sellprice, p.listprice, p.lastcost, p.rop,
  1277. p.avgcost, p.weight, p.priceupdate, p.image,
  1278. p.drawing, p.microfiche, p.assembly,
  1279. pg.partsgroup, p.notes
  1280. $makemodelflds $assemblyflds |;
  1281. } else {
  1282. # replace p.onhand with a.qty AS onhand
  1283. $flds =~ s/p\.onhand/a.qty AS perassembly/;
  1284. }
  1285. for (@{ $form->{parts} }) {
  1286. push @a, $_;
  1287. $_->{perassembly} = 1;
  1288. $flds =~ s/p\.onhand*AS perassembly/p\.onhand, a\.qty AS perassembly/;
  1289. push @a, &include_assembly(
  1290. $dbh, $myconfig, $form, $_->{id}, $flds,
  1291. $makemodeljoin);
  1292. push @a, {id => $_->{id}, assemblyitem => 1};
  1293. }
  1294. # copy assemblies to $form->{parts}
  1295. @{ $form->{parts} } = @a;
  1296. }
  1297. @a = ();
  1298. if (($form->{warehouse} ne "") || $form->{l_warehouse}) {
  1299. if ($form->{warehouse} ne "") {
  1300. my ($desc, $var) = split /--/, $form->{warehouse};
  1301. $var = $dbh->quote($var);
  1302. $desc = $dbh->quote($desc);
  1303. $query = qq|
  1304. SELECT SUM(qty) AS onhand,
  1305. $desc AS description
  1306. FROM inventory
  1307. WHERE warehouse_id = $var
  1308. AND parts_id = ?|;
  1309. } else {
  1310. $query = qq|
  1311. SELECT SUM(i.qty) AS onhand,
  1312. w.description AS warehouse
  1313. FROM inventory i
  1314. JOIN warehouse w ON (w.id = i.warehouse_id)
  1315. WHERE i.parts_id = ?
  1316. GROUP BY w.description|;
  1317. }
  1318. $sth = $dbh->prepare($query) || $form->dberror($query);
  1319. for (@{ $form->{parts} }) {
  1320. $sth->execute($_->{id}) || $form->dberror($query);
  1321. if ($form->{warehouse} ne "") {
  1322. $ref = $sth->fetchrow_hashref(NAME_lc);
  1323. if ($ref->{onhand} != 0) {
  1324. $_->{onhand} = $ref->{onhand};
  1325. push @a, $_;
  1326. }
  1327. } else {
  1328. push @a, $_;
  1329. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1330. if ($ref->{onhand} > 0) {
  1331. push @a, $ref;
  1332. }
  1333. }
  1334. }
  1335. $sth->finish;
  1336. }
  1337. @{ $form->{parts} } = @a;
  1338. }
  1339. $dbh->commit;
  1340. }
  1341. sub include_assembly {
  1342. my ($dbh, $myconfig, $form, $id, $flds, $makemodeljoin) = @_;
  1343. $form->{stagger}++;
  1344. if ($form->{stagger} > $form->{pncol}) {
  1345. $form->{pncol} = $form->{stagger};
  1346. }
  1347. $form->{$id} = 1;
  1348. my @a = qw(partnumber description bin);
  1349. if ($form->{sort} eq 'partnumber') {
  1350. $sortorder = "TRUE";
  1351. } else {
  1352. @a = grep !/$form->{sort}/, @a;
  1353. $sortorder = "$form->{sort} $form->{direction}, ". join ',', @a;
  1354. }
  1355. @a = ();
  1356. my $query = qq|
  1357. SELECT $flds
  1358. FROM parts p
  1359. JOIN assembly a ON (a.parts_id = p.id)
  1360. LEFT JOIN partsgroup pg ON (pg.id = p.id)
  1361. LEFT JOIN chart c1 ON (c1.id = p.inventory_accno_id)
  1362. LEFT JOIN chart c2 ON (c2.id = p.income_accno_id)
  1363. LEFT JOIN chart c3 ON (c3.id = p.expense_accno_id)
  1364. $makemodeljoin
  1365. WHERE a.id = ?
  1366. ORDER BY $sortorder|;
  1367. my $sth = $dbh->prepare($query);
  1368. $sth->execute($id) || $form->dberror($query);
  1369. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1370. $ref->{assemblyitem} = 1;
  1371. $ref->{stagger} = $form->{stagger};
  1372. push @a, $ref;
  1373. if ($ref->{assembly} && !$form->{$ref->{id}}) {
  1374. push @a, &include_assembly(
  1375. $dbh, $myconfig, $form, $ref->{id}, $flds,
  1376. $makemodeljoin);
  1377. if ($form->{stagger} > $form->{pncol}) {
  1378. $form->{pncol} = $form->{stagger};
  1379. }
  1380. }
  1381. }
  1382. $sth->finish;
  1383. $form->{$id} = 0;
  1384. $form->{stagger}--;
  1385. @a;
  1386. }
  1387. sub requirements {
  1388. my ($self, $myconfig, $form) = @_;
  1389. my $dbh = $form->{dbh};
  1390. my $null;
  1391. my $var;
  1392. my $ref;
  1393. my $where = qq|p.obsolete = '0'|;
  1394. my $dwhere;
  1395. for (qw(partnumber description)) {
  1396. if ($form->{$_} ne "") {
  1397. $var = $dbh->quote($form->like(lc $form->{$_}));
  1398. $where .= qq| AND lower(p.$_) LIKE $var|;
  1399. }
  1400. }
  1401. if ($form->{partsgroup} ne "") {
  1402. ($null, $var) = split /--/, $form->{partsgroup};
  1403. $var = $dbh->quote($var);
  1404. $where .= qq| AND p.partsgroup_id = $var|;
  1405. }
  1406. # connect to database
  1407. my ($transdatefrom, $transdateto);
  1408. if ($form->{year}) {
  1409. ($transdatefrom, $transdateto)
  1410. = $form->from_to($form->{year}, '01', 12);
  1411. $dwhere = qq| AND a.transdate >= '$transdatefrom'
  1412. AND a.transdate <= '$transdateto'|;
  1413. }
  1414. $query = qq|
  1415. SELECT p.id, p.partnumber, p.description, sum(i.qty) AS qty,
  1416. p.onhand, extract(MONTH FROM a.transdate) AS month,
  1417. '0' AS so, '0' AS po
  1418. FROM invoice i
  1419. JOIN parts p ON (p.id = i.parts_id)
  1420. JOIN ar a ON (a.id = i.trans_id)
  1421. WHERE $where $dwhere AND p.inventory_accno_id > 0
  1422. GROUP BY p.id, p.partnumber, p.description, p.onhand,
  1423. extract(MONTH FROM a.transdate)|;
  1424. my $sth = $dbh->prepare($query);
  1425. $sth->execute || $form->dberror($query);
  1426. my %parts;
  1427. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1428. $parts{$ref->{id}} = $ref;
  1429. }
  1430. $sth->finish;
  1431. my %ofld = ( customer => so, vendor => po );
  1432. for (qw(customer vendor)) {
  1433. $query = qq|
  1434. SELECT p.id, p.partnumber, p.description,
  1435. sum(qty) - sum(ship) AS $ofld{$_}, p.onhand,
  1436. 0 AS month
  1437. FROM orderitems i
  1438. JOIN parts p ON (p.id = i.parts_id)
  1439. JOIN oe a ON (a.id = i.trans_id)
  1440. WHERE $where AND p.inventory_accno_id > 0
  1441. AND p.assembly = '0' AND a.closed = '0'
  1442. AND a.${_}_id > 0
  1443. GROUP BY p.id, p.partnumber, p.description, p.onhand,
  1444. month|;
  1445. $sth = $dbh->prepare($query);
  1446. $sth->execute || $form->dberror($query);
  1447. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1448. if (exists $parts{$ref->{id}}->{$ofld{$_}}) {
  1449. $parts{$ref->{id}}->{$ofld{$_}}
  1450. += $ref->{$ofld{$_}};
  1451. } else {
  1452. $parts{$ref->{id}} = $ref;
  1453. }
  1454. }
  1455. $sth->finish;
  1456. }
  1457. # add assemblies from open sales orders
  1458. $query = qq|
  1459. SELECT DISTINCT a.id AS orderid, b.id, i.qty - i.ship AS qty
  1460. FROM parts p
  1461. JOIN assembly b ON (b.parts_id = p.id)
  1462. JOIN orderitems i ON (i.parts_id = b.id)
  1463. JOIN oe a ON (a.id = i.trans_id)
  1464. WHERE $where
  1465. AND (p.inventory_accno_id > 0 OR p.assembly = '1')
  1466. AND a.closed = '0'|;
  1467. $sth = $dbh->prepare($query);
  1468. $sth->execute || $form->dberror($query);
  1469. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1470. &requirements_assembly(
  1471. $dbh, $form, \%parts, $ref->{id}, $ref->{qty}, $where)
  1472. if $ref->{qty};
  1473. }
  1474. $sth->finish;
  1475. $dbh->commit;
  1476. for (sort { $parts{$a}->{$form->{sort}} cmp $parts{$b}->{$form->{sort}}} keys %parts) {
  1477. push @{ $form->{parts} }, $parts{$_};
  1478. }
  1479. }
  1480. sub requirements_assembly {
  1481. my ($dbh, $form, $parts, $id, $qty, $where) = @_;
  1482. # assemblies
  1483. my $query = qq|
  1484. SELECT p.id, p.partnumber, p.description, a.qty * ? AS so,
  1485. p.onhand, p.assembly, p.partsgroup_id
  1486. FROM assembly a
  1487. JOIN parts p ON (p.id = a.parts_id)
  1488. WHERE $where AND a.id = ? AND p.inventory_accno_id > 0
  1489. UNION
  1490. SELECT p.id, p.partnumber, p.description, a.qty * ? AS so,
  1491. p.onhand, p.assembly, p.partsgroup_id
  1492. FROM assembly a
  1493. JOIN parts p ON (p.id = a.parts_id)
  1494. WHERE a.id = ? AND p.assembly = '1'|;
  1495. my $sth = $dbh->prepare($query);
  1496. $sth->execute($qty, $id, $qty, $id) || $form->dberror($query);
  1497. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  1498. if ($ref->{assembly}) {
  1499. &requirements_assembly(
  1500. $dbh, $form, $parts, $ref->{id}, $ref->{so},
  1501. $where);
  1502. next;
  1503. }
  1504. if (exists $parts->{$ref->{id}}{so}) {
  1505. $parts->{$ref->{id}}{so} += $ref->{so};
  1506. } else {
  1507. $parts->{$ref->{id}} = $ref;
  1508. }
  1509. }
  1510. $sth->finish;
  1511. }
  1512. sub create_links {
  1513. my ($self, $module, $myconfig, $form) = @_;
  1514. # connect to database
  1515. my $dbh = $form->{dbh};
  1516. my $ref;
  1517. my $query = qq|
  1518. SELECT accno, description, link
  1519. FROM chart
  1520. WHERE link LIKE ?
  1521. ORDER BY accno|;
  1522. my $sth = $dbh->prepare($query);
  1523. $sth->execute("%$module%") || $form->dberror($query);
  1524. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1525. foreach my $key (split /:/, $ref->{link}) {
  1526. if ($key =~ /$module/) {
  1527. push @{ $form->{"${module}_links"}{$key} },
  1528. { accno => $ref->{accno},
  1529. description => $ref->{description} };
  1530. }
  1531. }
  1532. }
  1533. $sth->finish;
  1534. if ($form->{item} ne 'assembly') {
  1535. $query = qq|SELECT count(*) FROM vendor|;
  1536. my ($count) = $dbh->selectrow_array($query);
  1537. if ($count < $myconfig->{vclimit}) {
  1538. $query = qq|SELECT id, name FROM vendor ORDER BY name|;
  1539. $sth = $dbh->prepare($query);
  1540. $sth->execute || $form->dberror($query);
  1541. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1542. push @{ $form->{all_vendor} }, $ref;
  1543. }
  1544. $sth->finish;
  1545. }
  1546. }
  1547. # pricegroups, customers
  1548. $query = qq|SELECT count(*) FROM customer|;
  1549. ($count) = $dbh->selectrow_array($query);
  1550. if ($count < $myconfig->{vclimit}) {
  1551. $query = qq|SELECT id, name FROM customer ORDER BY name|;
  1552. $sth = $dbh->prepare($query);
  1553. $sth->execute || $form->dberror($query);
  1554. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1555. push @{ $form->{all_customer} }, $ref;
  1556. }
  1557. $sth->finish;
  1558. }
  1559. $query = qq|SELECT id, pricegroup FROM pricegroup ORDER BY pricegroup|;
  1560. $sth = $dbh->prepare($query);
  1561. $sth->execute || $form->dberror($query);
  1562. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1563. push @{ $form->{all_pricegroup} }, $ref;
  1564. }
  1565. $sth->finish;
  1566. if ($form->{id}) {
  1567. $query = qq|
  1568. SELECT value FROM defaults
  1569. WHERE setting_key = 'weightunit'|;
  1570. ($form->{weightunit}) = $dbh->selectrow_array($query);
  1571. $query = qq|
  1572. SELECT value FROM defaults
  1573. WHERE setting_key = 'curr'|;
  1574. ($form->{currencies}) = $dbh->selectrow_array($query);
  1575. } else {
  1576. # Dieter: FIXME left joins not working
  1577. $query = qq|
  1578. SELECT (SELECT value FROM defaults
  1579. WHERE setting_key = 'weightunit')
  1580. AS weightunit, current_date AS priceupdate,
  1581. (SELECT value FROM defaults
  1582. WHERE setting_key = 'curr') AS currencies,
  1583. c1.accno AS inventory_accno,
  1584. c1.description AS inventory_description,
  1585. c2.accno AS income_accno,
  1586. c2.description AS income_description,
  1587. c3.accno AS expense_accno,
  1588. c3.description AS expense_description
  1589. FROM chart c1, chart c2, chart c3
  1590. WHERE c1.id IN (SELECT value FROM defaults
  1591. WHERE setting_key = 'inventory_accno_id')
  1592. AND c2.id IN (SELECT value FROM defaults
  1593. WHERE setting_key = 'income_accno_id')
  1594. AND c3.id IN (SELECT value FROM defaults
  1595. WHERE setting_key
  1596. = 'expense_accno_id')|;
  1597. $sth = $dbh->prepare($query);
  1598. $sth->execute || $form->dberror($query);
  1599. $ref = $sth->fetchrow_hashref(NAME_lc);
  1600. for (qw(weightunit priceupdate currencies)) {
  1601. $form->{$_} = $ref->{$_};
  1602. }
  1603. # setup accno hash, {amount} is used in create_links
  1604. for (qw(inventory income expense)) {
  1605. $form->{amount}{"IC_$_"}
  1606. = {
  1607. accno => $ref->{"${_}_accno"},
  1608. description => $ref->{"${_}_description"}
  1609. };
  1610. }
  1611. $sth->finish;
  1612. }
  1613. $dbh->commit;
  1614. }
  1615. sub get_warehouses {
  1616. my ($self, $myconfig, $form) = @_;
  1617. my $dbh = $form->{dbh};
  1618. my $query = qq|SELECT id, description FROM warehouse|;
  1619. my $sth = $dbh->prepare($query);
  1620. $sth->execute || $form->dberror($query);
  1621. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  1622. push @{ $form->{all_warehouse} }, $ref;
  1623. }
  1624. $sth->finish;
  1625. $dbh->commit;
  1626. }
  1627. 1;