summaryrefslogtreecommitdiff
path: root/LedgerSMB/IC.pm
blob: 6bcfdd80280c4dfa37ed3d9f597bbe0fbd88bd31 (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. = $sth->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. if(!$form->{"bom_$i"}){
  406. $form->{"bom_$i"} = undef;
  407. }
  408. if ($form->{"id_$i"} && $form->{"qty_$i"}){
  409. $sth->execute(
  410. $form->{id}, $form->{"id_$i"},
  411. $form->{"qty_$i"}, $form->{"bom_$i"} || 0,
  412. $form->{"adj_$i"}
  413. ) || $form->dberror($query);
  414. }
  415. }
  416. }
  417. # adjust onhand for the parts
  418. if ($form->{onhand}) {
  419. &adjust_inventory(
  420. $dbh, $form, $form->{id}, $form->{onhand});
  421. }
  422. }
  423. # add vendors
  424. if ($form->{item} ne 'assembly') {
  425. $updparts{$form->{id}} = 1;
  426. for $i (1 .. $form->{vendor_rows}) {
  427. if (($form->{"vendor_$i"} ne "")
  428. && $form->{"lastcost_$i"}) {
  429. ($null, $vendor_id)
  430. = split /--/, $form->{"vendor_$i"};
  431. for (qw(lastcost leadtime)) {
  432. $form->{"${_}_$i"}
  433. = $form->parse_amount(
  434. $myconfig,
  435. $form->{"${_}_$i"});
  436. }
  437. $query = qq|
  438. INSERT INTO partsvendor
  439. (vendor_id, parts_id,
  440. partnumber, lastcost,
  441. leadtime, curr)
  442. VALUES (?, ?, ?, ?, ?, ?)|;
  443. $sth = $dbh->prepare($query);
  444. $sth->execute(
  445. $vendor_id, $form->{id},
  446. $form->{"partnumber_$i"},
  447. $form->{"lastcost_$i"},
  448. $form->{"leadtime_$i"},
  449. $form->{"vendorcurr_$i"}
  450. )|| $form->dberror($query);
  451. }
  452. }
  453. }
  454. # add pricematrix
  455. for $i (1 .. $form->{customer_rows}) {
  456. for (qw(pricebreak customerprice)) {
  457. $form->{"${_}_$i"} = $form->parse_amount(
  458. $myconfig, $form->{"${_}_$i"});
  459. }
  460. if ($form->{"customerprice_$i"}) {
  461. ($null, $customer_id)
  462. = split /--/, $form->{"customer_$i"};
  463. $customer_id *= 1;
  464. ($null, $pricegroup_id)
  465. = split /--/, $form->{"pricegroup_$i"};
  466. my $validfrom;
  467. my $validto;
  468. $validfrom = $form->{"validfrom_$i"} if $form->{"validfrom_$i"};
  469. $validto = $form->{"validto_$i"} if $form->{"validto_$i"};
  470. $query = qq|
  471. INSERT INTO partscustomer
  472. (parts_id, customer_id,
  473. pricegroup_id, pricebreak,
  474. sellprice, curr,
  475. validfrom, validto)
  476. VALUES (?, ?, ?, ?, ?, ?, ?, ?)|;
  477. $sth = $dbh->prepare($query);
  478. $sth->execute(
  479. $form->{id}, $customer_id, $pricegroup_id,
  480. $form->{"pricebreak_$i"},
  481. $form->{"customerprice_$i"},
  482. $form->{"customercurr_$i"},
  483. $validfrom, $validto
  484. )|| $form->dberror($query);
  485. }
  486. }
  487. my $rc = $dbh->commit;
  488. $form->run_custom_queries('parts', 'UPDATE');
  489. $rc;
  490. }
  491. sub update_assembly {
  492. my ($dbh, $form, $id, $qty, $adj, $listprice, $sellprice, $lastcost,
  493. $weight) = @_;
  494. my $formlistprice = $form->{listprice};
  495. my $formsellprice = $form->{sellprice};
  496. if (!$adj) {
  497. $formlistprice = $listprice;
  498. $formsellprice = $sellprice;
  499. }
  500. my $query = qq|SELECT id, qty, adj FROM assembly WHERE parts_id = ?|;
  501. my $sth = $dbh->prepare($query);
  502. $sth->execute($id) || $form->dberror($query);
  503. $form->{$id} = 1; # Not sure what this is for...
  504. # In fact, we don't seem to use it... Chris T
  505. while (my ($pid, $aqty, $aadj) = $sth->fetchrow_array) {
  506. &update_assembly($dbh, $form, $pid, $aqty * $qty, $aadj,
  507. $listprice, $sellprice, $lastcost, $weight)
  508. if !$form->{$pid};
  509. }
  510. $sth->finish;
  511. $qty = $dbh->quote($qty);
  512. $formlistprice = $dbh->quote($formlistprice - $listprice);
  513. $formsellprice = $dbh->quote($formsellprice - $sellprice);
  514. $formlastcost = $dbh->quote($form->{lastcost} - $lastcost);
  515. $weight = $dbh->quote($form->{weight} - $weight);
  516. $id = $dbh->quote($id);
  517. $query = qq|
  518. UPDATE parts
  519. SET listprice = listprice +
  520. $qty * cast($formlistprice AS numeric),
  521. sellprice = sellprice +
  522. $qty * cast($formsellprice AS numeric),
  523. lastcost = lastcost +
  524. $qty * cast($formlastcost AS numeric),
  525. weight = weight +
  526. $qty * cast($weight AS numeric)
  527. WHERE id = $id|;
  528. $dbh->do($query) || $form->dberror($query);
  529. delete $form->{$id};
  530. }
  531. sub retrieve_assemblies {
  532. my ($self, $myconfig, $form) = @_;
  533. # connect to database
  534. my $dbh = $form->{dbh};
  535. my $where = '1 = 1';
  536. if ($form->{partnumber} ne "") {
  537. my $partnumber = $dbh->quote($form->like(
  538. lc $form->{partnumber}));
  539. $where .= " AND lower(p.partnumber) LIKE $partnumber";
  540. }
  541. if ($form->{description} ne "") {
  542. my $description = $dbh->($form->like(lc $form->{description}));
  543. $where .= " AND lower(p.description) LIKE $description";
  544. }
  545. $where .= qq| AND p.obsolete = '0'
  546. AND p.project_id IS NULL|;
  547. my %ordinal = (
  548. 'partnumber' => 2,
  549. 'description' => 3,
  550. 'bin' => 4
  551. );
  552. my @a = qw(partnumber description bin);
  553. my $sortorder = $form->sort_order(\@a, \%ordinal);
  554. # retrieve assembly items
  555. my $query = qq|
  556. SELECT p.id, p.partnumber, p.description, p.bin, p.onhand,
  557. p.rop
  558. FROM parts p
  559. WHERE $where
  560. AND p.assembly = '1'
  561. ORDER BY $sortorder|;
  562. my $sth = $dbh->prepare($query);
  563. $sth->execute || $form->dberror($query);
  564. $query = qq|
  565. SELECT sum(p.inventory_accno_id), p.assembly
  566. FROM parts p
  567. JOIN assembly a ON (a.parts_id = p.id)
  568. WHERE a.id = ?
  569. GROUP BY p.assembly|;
  570. my $svh = $dbh->prepare($query) || $form->dberror($query);
  571. my $inh;
  572. if ($form->{checkinventory}) {
  573. $query = qq|
  574. SELECT p.id, p.onhand, a.qty
  575. FROM parts p
  576. JOIN assembly a ON (a.parts_id = p.id)
  577. WHERE (p.inventory_accno_id > 0 OR p.assembly)
  578. AND p.income_accno_id > 0 AND a.id = ?|;
  579. $inh = $dbh->prepare($query) || $form->dberror($query);
  580. }
  581. my %available = ();
  582. my %required;
  583. my $ref;
  584. my $aref;
  585. my $stock;
  586. my $howmany;
  587. my $ok;
  588. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  589. $svh->execute($ref->{id});
  590. ($ref->{inventory}, $ref->{assembly}) = $svh->fetchrow_array;
  591. $svh->finish;
  592. if ($ref->{inventory} || $ref->{assembly}) {
  593. $ok = 1;
  594. if ($form->{checkinventory}) {
  595. $inh->execute($ref->{id})
  596. || $form->dberror($query);;
  597. $ok = 0;
  598. %required = ();
  599. while ($aref
  600. = $inh->fetchrow_hashref(NAME_lc)) {
  601. $available{$aref->{id}} =
  602. (exists $available{$aref->{id}})
  603. ? $available{$aref->{id}}
  604. : $aref->{onhand};
  605. $required{$aref->{id}} = $aref->{qty};
  606. if ($available{$aref->{id}}
  607. >= $aref->{qty}) {
  608. $howmany =
  609. ($aref->{qty})
  610. ? int $available{
  611. $aref->{id}}
  612. /$aref->{qty}
  613. : 1;
  614. if ($stock) {
  615. $stock =
  616. ($stock
  617. > $howmany)
  618. ? $howmany
  619. : $stock;
  620. } else {
  621. $stock = $howmany;
  622. }
  623. $ok = 1;
  624. $available{$aref->{id}}
  625. -= $aref->{qty}
  626. * $stock;
  627. } else {
  628. $ok = 0;
  629. for (keys %required) {
  630. $available{$_} +=
  631. $required{$_}
  632. * $stock;
  633. }
  634. $stock = 0;
  635. last;
  636. }
  637. }
  638. $inh->finish;
  639. $ref->{stock} = $stock;
  640. }
  641. push @{ $form->{assembly_items} }, $ref if $ok;
  642. }
  643. }
  644. $sth->finish;
  645. $dbh->commit;
  646. }
  647. sub restock_assemblies {
  648. my ($self, $myconfig, $form) = @_;
  649. # connect to database
  650. my $dbh = $form->{dbh};
  651. for my $i (1 .. $form->{rowcount}) {
  652. $form->{"qty_$i"} = $form->parse_amount(
  653. $myconfig, $form->{"qty_$i"});
  654. if ($form->{"qty_$i"}) {
  655. &adjust_inventory(
  656. $dbh, $form, $form->{"id_$i"},
  657. $form->{"qty_$i"});
  658. }
  659. }
  660. my $rc = $dbh->commit;
  661. $rc;
  662. }
  663. sub adjust_inventory {
  664. # Private method. Do not commit transaction at end of function...
  665. my ($dbh, $form, $id, $qty) = @_;
  666. my $query = qq|
  667. SELECT p.id, p.inventory_accno_id, p.assembly, a.qty
  668. FROM parts p
  669. JOIN assembly a ON (a.parts_id = p.id)
  670. WHERE a.id = ?|;
  671. my $sth = $dbh->prepare($query);
  672. $sth->execute($id) || $form->dberror($query);
  673. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  674. # is it a service item then loop
  675. if (! $ref->{inventory_accno_id}) {
  676. next if ! $ref->{assembly};
  677. }
  678. # adjust parts onhand
  679. $form->update_balance(
  680. $dbh, "parts", "onhand", qq|id = $ref->{id}|,
  681. $qty * $ref->{qty} * -1);
  682. }
  683. $sth->finish;
  684. # update assembly
  685. $form->update_balance($dbh, "parts", "onhand", qq|id = $id|, $qty);
  686. }
  687. sub delete {
  688. my ($self, $myconfig, $form) = @_;
  689. my $dbh = $form->{dbh};
  690. my $query;
  691. $query = qq|DELETE FROM parts WHERE id = ?|;
  692. $sth = $dbh->prepare($query);
  693. $sth->execute($form->{id}) || $form->dberror($query);
  694. $query = qq|DELETE FROM partstax WHERE parts_id = ?|;
  695. $sth = $dbh->prepare($query);
  696. $sth->execute($form->{id}) || $form->dberror($query);
  697. if ($form->{item} ne 'assembly') {
  698. $query = qq|DELETE FROM partsvendor WHERE parts_id = ?|;
  699. $sth = $dbh->prepare($query);
  700. $sth->execute($form->{id}) || $form->dberror($query);
  701. }
  702. # check if it is a part, assembly or service
  703. if ($form->{item} ne 'service') {
  704. $query = qq|DELETE FROM makemodel WHERE parts_id = ?|;
  705. $sth = $dbh->prepare($query);
  706. $sth->execute($form->{id}) || $form->dberror($query);
  707. }
  708. if ($form->{item} eq 'assembly') {
  709. $query = qq|DELETE FROM assembly WHERE id = ?|;
  710. $sth = $dbh->prepare($query);
  711. $sth->execute($form->{id}) || $form->dberror($query);
  712. }
  713. $query = qq|DELETE FROM inventory WHERE parts_id = ?|;
  714. $sth = $dbh->prepare($query);
  715. $sth->execute($form->{id}) || $form->dberror($query);
  716. $query = qq|DELETE FROM partscustomer WHERE parts_id = ?|;
  717. $sth = $dbh->prepare($query);
  718. $sth->execute($form->{id}) || $form->dberror($query);
  719. $query = qq|DELETE FROM translation WHERE trans_id = ?|;
  720. $sth = $dbh->prepare($query);
  721. $sth->execute($form->{id}) || $form->dberror($query);
  722. # commit
  723. my $rc = $dbh->commit;
  724. $rc;
  725. }
  726. sub assembly_item {
  727. my ($self, $myconfig, $form) = @_;
  728. my $dbh = $form->{dbh};
  729. my $i = $form->{assembly_rows};
  730. my $var;
  731. my $null;
  732. my $where = "p.obsolete = '0'";
  733. if ($form->{"partnumber_$i"} ne "") {
  734. $var = $dbh->quote($form->like(lc $form->{"partnumber_$i"}));
  735. $where .= " AND lower(p.partnumber) LIKE $var";
  736. }
  737. if ($form->{"description_$i"} ne "") {
  738. $var = $dbh->quote($form->like(lc $form->{"description_$i"}));
  739. $where .= " AND lower(p.description) LIKE $var";
  740. }
  741. if ($form->{"partsgroup_$i"} ne "") {
  742. ($null, $var) = split /--/, $form->{"partsgroup_$i"};
  743. $var = $dbh->quote($var);
  744. $where .= qq| AND p.partsgroup_id = $var|;
  745. }
  746. if ($form->{id}) {
  747. $where .= " AND p.id != ".$dbh->quote($form->{id});
  748. }
  749. if ($form->{"description_$i"} ne "") {
  750. $where .= " ORDER BY p.description";
  751. } else {
  752. $where .= " ORDER BY p.partnumber";
  753. }
  754. my $query = qq|
  755. SELECT p.id, p.partnumber, p.description, p.sellprice,
  756. p.weight, p.onhand, p.unit, p.lastcost,
  757. pg.partsgroup, p.partsgroup_id
  758. FROM parts p
  759. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  760. WHERE $where|;
  761. my $sth = $dbh->prepare($query);
  762. $sth->execute || $form->dberror($query);
  763. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  764. push @{ $form->{item_list} }, $ref;
  765. }
  766. $sth->finish;
  767. }
  768. sub all_parts {
  769. my ($self, $myconfig, $form) = @_;
  770. $dbh = $form->{dbh};
  771. my $where = '1 = 1';
  772. my $null;
  773. my $var;
  774. my $ref;
  775. for (qw(partnumber drawing microfiche)) {
  776. if ($form->{$_} ne "") {
  777. $var = $dbh->quote($form->like(lc $form->{$_}));
  778. $where .= " AND lower(p.$_) LIKE $var";
  779. }
  780. }
  781. # special case for description
  782. if ($form->{description} ne "") {
  783. unless ($form->{bought} || $form->{sold} || $form->{onorder}
  784. || $form->{ordered} || $form->{rfq} || $form->{quoted}
  785. ) {
  786. $var = $dbh->quote($form->like(
  787. lc $form->{description}));
  788. $where .= " AND lower(p.description) LIKE $var";
  789. }
  790. }
  791. # assembly components
  792. my $assemblyflds;
  793. if ($form->{searchitems} eq 'component') {
  794. $assemblyflds = qq|, p1.partnumber AS assemblypartnumber,
  795. a.id AS assembly_id|;
  796. }
  797. # special case for serialnumber
  798. if ($form->{l_serialnumber}) {
  799. if ($form->{serialnumber} ne "") {
  800. $var = $dbh->quote(
  801. $form->like(lc $form->{serialnumber}));
  802. $where .= " AND lower(i.serialnumber) LIKE $var";
  803. }
  804. }
  805. if (($form->{warehouse} ne "") || $form->{l_warehouse}) {
  806. $form->{l_warehouse} = 1;
  807. }
  808. if ($form->{searchitems} eq 'part') {
  809. $where .= " AND p.inventory_accno_id > 0 AND p.income_accno_id > 0";
  810. }
  811. if ($form->{searchitems} eq 'assembly') {
  812. $form->{bought} = "";
  813. $where .= " AND p.assembly = '1'";
  814. }
  815. if ($form->{searchitems} eq 'service') {
  816. $where .= " AND p.assembly = '0' AND p.inventory_accno_id IS NULL";
  817. }
  818. if ($form->{searchitems} eq 'labor') {
  819. $where .= " AND p.inventory_accno_id > 0 AND p.income_accno_id IS NULL";
  820. }
  821. # items which were never bought, sold or on an order
  822. if ($form->{itemstatus} eq 'orphaned') {
  823. $where .= qq|
  824. AND p.onhand = 0
  825. AND p.id NOT IN (SELECT p.id FROM parts p
  826. JOIN invoice i
  827. ON (p.id = i.parts_id))
  828. AND p.id NOT IN (SELECT p.id FROM parts p
  829. JOIN assembly a
  830. ON (p.id = a.parts_id))
  831. AND p.id NOT IN (SELECT p.id FROM parts p
  832. JOIN orderitems o
  833. ON (p.id = o.parts_id))
  834. AND p.id NOT IN (SELECT p.id FROM parts p
  835. JOIN jcitems j
  836. ON (p.id = j.parts_id))|;
  837. }
  838. if ($form->{itemstatus} eq 'active') {
  839. $where .= " AND p.obsolete = '0'";
  840. }
  841. if ($form->{itemstatus} eq 'obsolete') {
  842. $where .= " AND p.obsolete = '1'";
  843. }
  844. if ($form->{itemstatus} eq 'onhand') {
  845. $where .= " AND p.onhand > 0";
  846. }
  847. if ($form->{itemstatus} eq 'short') {
  848. $where .= " AND p.onhand < p.rop";
  849. }
  850. my $makemodelflds = qq|, '', ''|;;
  851. my $makemodeljoin;
  852. if (($form->{make} ne "") || $form->{l_make} || ($form->{model} ne "")
  853. || $form->{l_model}) {
  854. $makemodelflds = qq|, m.make, m.model|;
  855. $makemodeljoin = qq|LEFT JOIN makemodel m ON (m.parts_id = p.id)|;
  856. if ($form->{make} ne "") {
  857. $var = $dbh->quote($form->like(lc $form->{make}));
  858. $where .= " AND lower(m.make) LIKE $var";
  859. }
  860. if ($form->{model} ne "") {
  861. $var = $dbh->quote($form->like(lc $form->{model}));
  862. $where .= " AND lower(m.model) LIKE $var";
  863. }
  864. }
  865. if ($form->{partsgroup} ne "") {
  866. ($null, $var) = split /--/, $form->{partsgroup};
  867. $where .= qq| AND p.partsgroup_id = | . $dbh->quote($var);
  868. }
  869. my %ordinal = (
  870. 'partnumber' => 2,
  871. 'description' => 3,
  872. 'bin' => 6,
  873. 'priceupdate' => 13,
  874. 'drawing' => 15,
  875. 'microfiche' => 16,
  876. 'partsgroup' => 18,
  877. 'make' => 21,
  878. 'model' => 22,
  879. 'assemblypartnumber' => 23
  880. );
  881. my @a = qw(partnumber description);
  882. my $sortorder = $form->sort_order(\@a, \%ordinal);
  883. my $query = qq|SELECT value FROM defaults WHERE setting_key = 'curr'|;
  884. my ($curr) = $dbh->selectrow_array($query);
  885. $curr =~ s/:.*//;
  886. $curr = $dbh->quote($curr);
  887. my $flds = qq|
  888. p.id, p.partnumber, p.description, p.onhand, p.unit,
  889. p.bin, p.sellprice, p.listprice, p.lastcost, p.rop,
  890. p.avgcost,
  891. p.weight, p.priceupdate, p.image, p.drawing, p.microfiche,
  892. p.assembly, pg.partsgroup, $curr AS curr,
  893. c1.accno AS inventory, c2.accno AS income, c3.accno AS expense,
  894. p.notes
  895. $makemodelflds $assemblyflds
  896. |;
  897. $query = qq|
  898. SELECT $flds
  899. FROM parts p
  900. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  901. LEFT JOIN chart c1 ON (c1.id = p.inventory_accno_id)
  902. LEFT JOIN chart c2 ON (c2.id = p.income_accno_id)
  903. LEFT JOIN chart c3 ON (c3.id = p.expense_accno_id)
  904. $makemodeljoin
  905. WHERE $where
  906. ORDER BY $sortorder|;
  907. # redo query for components report
  908. if ($form->{searchitems} eq 'component') {
  909. $flds =~ s/p.onhand/a.qty AS onhand/;
  910. $query = qq|
  911. SELECT $flds
  912. FROM assembly a
  913. JOIN parts p ON (a.parts_id = p.id)
  914. JOIN parts p1 ON (a.id = p1.id)
  915. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  916. LEFT JOIN chart c1 ON (c1.id = p.inventory_accno_id)
  917. LEFT JOIN chart c2 ON (c2.id = p.income_accno_id)
  918. LEFT JOIN chart c3 ON (c3.id = p.expense_accno_id)
  919. $makemodeljoin
  920. WHERE $where
  921. ORDER BY $sortorder|;
  922. }
  923. # rebuild query for bought and sold items
  924. if ($form->{bought} || $form->{sold} || $form->{onorder}
  925. || $form->{ordered} || $form->{rfq} || $form->{quoted}
  926. ) {
  927. $form->sort_order();
  928. @a = qw(partnumber description curr employee name
  929. serialnumber id);
  930. push @a, "invnumber" if ($form->{bought} || $form->{sold});
  931. push @a, "ordnumber" if ($form->{onorder} || $form->{ordered});
  932. push @a, "quonumber" if ($form->{rfq} || $form->{quoted});
  933. %ordinal = (
  934. 'partnumber' => 2,
  935. 'description' => 3,
  936. 'serialnumber' => 4,
  937. 'bin' => 7,
  938. 'priceupdate' => 14,
  939. 'partsgroup' => 19,
  940. 'invnumber' => 20,
  941. 'ordnumber' => 21,
  942. 'quonumber' => 22,
  943. 'name' => 24,
  944. 'employee' => 25,
  945. 'curr' => 26,
  946. 'make' => 29,
  947. 'model' => 30
  948. );
  949. $sortorder = $form->sort_order(\@a, \%ordinal);
  950. my $union = "";
  951. $query = "";
  952. if ($form->{bought} || $form->{sold}) {
  953. my $invwhere = "$where";
  954. my $transdate =
  955. ($form->{method} eq 'accrual')
  956. ? "transdate"
  957. : "datepaid";
  958. $invwhere .= " AND i.assemblyitem = '0'";
  959. $invwhere .= " AND a.$transdate >= " .
  960. $dbh->quote($form->{transdatefrom})
  961. if $form->{transdatefrom};
  962. $invwhere .= " AND a.$transdate <= " .
  963. $dbh->quote($form->{transdateto})
  964. if $form->{transdateto};
  965. if ($form->{description} ne "") {
  966. $var = dbh->quote(
  967. $form->like(lc $form->{description}));
  968. $invwhere .=
  969. " AND lower(i.description) LIKE $var";
  970. }
  971. if ($form->{open} || $form->{closed}) {
  972. if ($form->{open} && $form->{closed}) {
  973. if ($form->{method} eq 'cash') {
  974. $invwhere .=
  975. " AND a.amount = a.paid";
  976. }
  977. } else {
  978. if ($form->{open}) {
  979. if ($form->{method} eq 'cash') {
  980. $invwhere .=
  981. " AND a.id = 0";
  982. } else {
  983. $invwhere .=
  984. " AND NOT a.amount = a.paid";
  985. }
  986. } else {
  987. $invwhere .=
  988. " AND a.amount = a.paid";
  989. }
  990. }
  991. } else {
  992. $invwhere .= " AND a.id = 0";
  993. }
  994. my $flds = qq|
  995. p.id, p.partnumber, i.description,
  996. i.serialnumber, i.qty AS onhand, i.unit, p.bin,
  997. i.sellprice, p.listprice, p.lastcost, p.rop,
  998. p.weight, p.avgcost, p.priceupdate, p.image,
  999. p.drawing, p.microfiche, p.assembly,
  1000. pg.partsgroup, a.invnumber, a.ordnumber,
  1001. a.quonumber, i.trans_id, ct.name,
  1002. e.name AS employee, a.curr, a.till, p.notes
  1003. $makemodelfld|;
  1004. if ($form->{bought}) {
  1005. my $rflds = $flds;
  1006. $rflds =~
  1007. s/i.qty AS onhand/i.qty * -1 AS onhand/;
  1008. $query = qq|
  1009. SELECT $rflds, 'ir' AS module,
  1010. '' AS type,
  1011. (SELECT sell
  1012. FROM exchangerate ex
  1013. WHERE ex.curr = a.curr
  1014. AND ex.transdate
  1015. = a.$transdate)
  1016. AS exchangerate, i.discount
  1017. FROM invoice i
  1018. JOIN parts p
  1019. ON (p.id = i.parts_id)
  1020. JOIN ap a ON (a.id = i.trans_id)
  1021. JOIN vendor ct
  1022. ON (a.vendor_id = ct.id)
  1023. LEFT JOIN partsgroup pg
  1024. ON (p.partsgroup_id = pg.id)
  1025. LEFT JOIN employee e
  1026. ON (a.employee_id = e.id)
  1027. $makemodeljoin
  1028. WHERE $invwhere|;
  1029. $union = "
  1030. UNION ALL";
  1031. }
  1032. if ($form->{sold}) {
  1033. $query .= qq|
  1034. $union
  1035. SELECT $flds, 'is' AS module,
  1036. '' AS type,
  1037. (SELECT buy
  1038. FROM exchangerate ex
  1039. WHERE ex.curr = a.curr
  1040. AND ex.transdate
  1041. = a.$transdate)
  1042. AS exchangerate, i.discount
  1043. FROM invoice i
  1044. JOIN parts p
  1045. ON (p.id = i.parts_id)
  1046. JOIN ar a ON (a.id = i.trans_id)
  1047. JOIN customer ct
  1048. ON (a.customer_id = ct.id)
  1049. LEFT JOIN partsgroup pg
  1050. ON (p.partsgroup_id = pg.id)
  1051. LEFT JOIN employee e
  1052. ON (a.employee_id = e.id)
  1053. $makemodeljoin
  1054. WHERE $invwhere|;
  1055. $union = "
  1056. UNION ALL";
  1057. }
  1058. }
  1059. if ($form->{onorder} || $form->{ordered}) {
  1060. my $ordwhere = "$where
  1061. AND a.quotation = '0'";
  1062. $ordwhere .= " AND a.transdate >= ".
  1063. $dbh->quote($form->{transdatefrom})
  1064. if $form->{transdatefrom};
  1065. $ordwhere .= " AND a.transdate <= ".
  1066. $dbh->quote($form->{transdateto})
  1067. if $form->{transdateto};
  1068. if ($form->{description} ne "") {
  1069. $var = $dbh->quote(
  1070. $form->like(lc $form->{description}));
  1071. $ordwhere .= " AND lower(i.description) LIKE $var";
  1072. }
  1073. if ($form->{open} || $form->{closed}) {
  1074. unless ($form->{open} && $form->{closed}) {
  1075. $ordwhere .= " AND a.closed = '0'"
  1076. if $form->{open};
  1077. $ordwhere .= " AND a.closed = '1'"
  1078. if $form->{closed};
  1079. }
  1080. } else {
  1081. $ordwhere .= " AND a.id = 0";
  1082. }
  1083. $flds = qq|
  1084. p.id, p.partnumber, i.description,
  1085. i.serialnumber, i.qty AS onhand, i.unit, p.bin,
  1086. i.sellprice, p.listprice, p.lastcost, p.rop,
  1087. p.weight, p.avgcost, p.priceupdate, p.image,
  1088. p.drawing, p.microfiche, p.assembly,
  1089. pg.partsgroup, '' AS invnumber, a.ordnumber,
  1090. a.quonumber, i.trans_id, ct.name,
  1091. e.name AS employee, a.curr, '0' AS till,
  1092. p.notes
  1093. $makemodelfld|;
  1094. if ($form->{ordered}) {
  1095. $query .= qq|
  1096. $union
  1097. SELECT $flds, 'oe' AS module,
  1098. 'sales_order' AS type,
  1099. (SELECT buy
  1100. FROM exchangerate ex
  1101. WHERE ex.curr = a.curr
  1102. AND ex.transdate
  1103. = a.transdate)
  1104. AS exchangerate, i.discount
  1105. FROM orderitems i
  1106. JOIN parts p ON (i.parts_id = p.id)
  1107. JOIN oe a ON (i.trans_id = a.id)
  1108. JOIN customer ct
  1109. ON (a.customer_id = ct.id)
  1110. LEFT JOIN partsgroup pg
  1111. ON (p.partsgroup_id = pg.id)
  1112. LEFT JOIN employee e
  1113. ON (a.employee_id = e.id)
  1114. $makemodeljoin
  1115. WHERE $ordwhere
  1116. AND a.customer_id > 0|;
  1117. $union = "
  1118. UNION ALL";
  1119. }
  1120. if ($form->{onorder}) {
  1121. $flds = qq|
  1122. p.id, p.partnumber, i.description,
  1123. i.serialnumber, i.qty AS onhand, i.unit,
  1124. p.bin, i.sellprice, p.listprice,
  1125. p.lastcost, p.rop, p.weight, p.avgcost,
  1126. p.priceupdate, p.image, p.drawing,
  1127. p.microfiche, p.assembly,
  1128. pg.partsgroup, '' AS invnumber,
  1129. a.ordnumber, a.quonumber,
  1130. i.trans_id, ct.name,e.name AS employee,
  1131. a.curr, '0' AS till, p.notes
  1132. $makemodelfld|;
  1133. $query .= qq|
  1134. $union
  1135. SELECT $flds, 'oe' AS module,
  1136. 'purchase_order' AS type,
  1137. (SELECT sell
  1138. FROM exchangerate ex
  1139. WHERE ex.curr = a.curr
  1140. AND ex.transdate
  1141. = a.transdate)
  1142. AS exchangerate, i.discount
  1143. FROM orderitems i
  1144. JOIN parts p ON (i.parts_id = p.id)
  1145. JOIN oe a ON (i.trans_id = a.id)
  1146. JOIN vendor ct
  1147. ON (a.vendor_id = ct.id)
  1148. LEFT JOIN partsgroup pg
  1149. ON (p.partsgroup_id = pg.id)
  1150. LEFT JOIN employee e
  1151. ON (a.employee_id = e.id)
  1152. $makemodeljoin
  1153. WHERE $ordwhere
  1154. AND a.vendor_id > 0|;
  1155. }
  1156. }
  1157. if ($form->{rfq} || $form->{quoted}) {
  1158. my $quowhere = "$where
  1159. AND a.quotation = '1'";
  1160. $quowhere .= " AND a.transdate >= ".
  1161. $dbh->quote($form->{transdatefrom})
  1162. if $form->{transdatefrom};
  1163. $quowhere .= " AND a.transdate <= ".
  1164. $dbh->quote($form->{transdateto})
  1165. if $form->{transdateto};
  1166. if ($form->{description} ne "") {
  1167. $var = $dbh->quote(
  1168. $form->like(lc $form->{description}));
  1169. $quowhere .= " AND lower(i.description) LIKE $var";
  1170. }
  1171. if ($form->{open} || $form->{closed}) {
  1172. unless ($form->{open} && $form->{closed}) {
  1173. $ordwhere .= " AND a.closed = '0'"
  1174. if $form->{open};
  1175. $ordwhere .= " AND a.closed = '1'"
  1176. if $form->{closed};
  1177. }
  1178. } else {
  1179. $ordwhere .= " AND a.id = 0";
  1180. }
  1181. $flds = qq|
  1182. p.id, p.partnumber, i.description,
  1183. i.serialnumber, i.qty AS onhand, i.unit, p.bin,
  1184. i.sellprice, p.listprice, p.lastcost, p.rop,
  1185. p.weight, p.avgcost, p.priceupdate, p.image,
  1186. p.drawing, p.microfiche, p.assembly,
  1187. pg.partsgroup, '' AS invnumber, a.ordnumber,
  1188. a.quonumber, i.trans_id, ct.name,
  1189. e.name AS employee, a.curr, '0' AS till, p.notes
  1190. $makemodelfld|;
  1191. if ($form->{quoted}) {
  1192. $query .= qq|
  1193. $union
  1194. SELECT $flds, 'oe' AS module,
  1195. 'sales_quotation' AS type,
  1196. (SELECT buy
  1197. FROM exchangerate ex
  1198. WHERE ex.curr = a.curr
  1199. AND ex.transdate
  1200. = a.transdate)
  1201. AS exchangerate,
  1202. i.discount
  1203. FROM orderitems i
  1204. JOIN parts p ON (i.parts_id = p.id)
  1205. JOIN oe a ON (i.trans_id = a.id)
  1206. JOIN customer ct
  1207. ON (a.customer_id = ct.id)
  1208. LEFT JOIN partsgroup pg
  1209. ON (p.partsgroup_id = pg.id)
  1210. LEFT JOIN employee e
  1211. ON (a.employee_id = e.id)
  1212. $makemodeljoin
  1213. WHERE $quowhere
  1214. AND a.customer_id > 0|;
  1215. $union = "
  1216. UNION ALL";
  1217. }
  1218. if ($form->{rfq}) {
  1219. $flds = qq|
  1220. p.id, p.partnumber, i.description,
  1221. i.serialnumber, i.qty AS onhand,
  1222. i.unit, p.bin, i.sellprice, p.listprice,
  1223. p.lastcost, p.rop, p.weight, p.avgcost,
  1224. p.priceupdate, p.image, p.drawing,
  1225. p.microfiche, p.assembly,
  1226. pg.partsgroup, '' AS invnumber,
  1227. a.ordnumber, a.quonumber,
  1228. i.trans_id, ct.name, e.name AS employee,
  1229. a.curr, '0' AS till, p.notes
  1230. $makemodelfld|;
  1231. $query .= qq|
  1232. $union
  1233. SELECT $flds, 'oe' AS module,
  1234. 'request_quotation' AS type,
  1235. (SELECT sell
  1236. FROM exchangerate ex
  1237. WHERE ex.curr = a.curr
  1238. AND ex.transdate
  1239. = a.transdate)
  1240. AS exchangerate, i.discount
  1241. FROM orderitems i
  1242. JOIN parts p ON (i.parts_id = p.id)
  1243. JOIN oe a ON (i.trans_id = a.id)
  1244. JOIN vendor ct
  1245. ON (a.vendor_id = ct.id)
  1246. LEFT JOIN partsgroup pg
  1247. ON (p.partsgroup_id = pg.id)
  1248. LEFT JOIN employee e
  1249. ON (a.employee_id = e.id)
  1250. $makemodeljoin
  1251. WHERE $quowhere
  1252. AND a.vendor_id > 0|;
  1253. }
  1254. }
  1255. $query .= qq|
  1256. ORDER BY $sortorder|;
  1257. }
  1258. my $sth = $dbh->prepare($query);
  1259. $sth->execute || $form->dberror($query);
  1260. $query = qq|
  1261. SELECT c.accno
  1262. FROM chart c
  1263. JOIN partstax pt ON (pt.chart_id = c.id)
  1264. WHERE pt.parts_id = ?
  1265. ORDER BY accno|;
  1266. my $pth = $dbh->prepare($query) || $form->dberror($query);
  1267. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1268. $pth->execute($ref->{id});
  1269. while (($accno) = $pth->fetchrow_array) {
  1270. $ref->{tax} .= "$accno ";
  1271. }
  1272. $pth->finish;
  1273. push @{ $form->{parts} }, $ref;
  1274. }
  1275. $sth->finish;
  1276. @a = ();
  1277. # include individual items for assembly
  1278. if (($form->{searchitems} eq 'assembly') && $form->{individual}) {
  1279. if ($form->{sold} || $form->{ordered} || $form->{quoted}) {
  1280. $flds = qq|
  1281. p.id, p.partnumber, p.description,
  1282. p.onhand AS perassembly, p.unit, p.bin,
  1283. p.sellprice, p.listprice, p.lastcost, p.rop,
  1284. p.avgcost, p.weight, p.priceupdate, p.image,
  1285. p.drawing, p.microfiche, p.assembly,
  1286. pg.partsgroup, p.notes
  1287. $makemodelflds $assemblyflds |;
  1288. } else {
  1289. # replace p.onhand with a.qty AS onhand
  1290. $flds =~ s/p\.onhand/a.qty AS perassembly/;
  1291. }
  1292. for (@{ $form->{parts} }) {
  1293. push @a, $_;
  1294. $_->{perassembly} = 1;
  1295. $flds =~ s/p\.onhand*AS perassembly/p\.onhand, a\.qty AS perassembly/;
  1296. push @a, &include_assembly(
  1297. $dbh, $myconfig, $form, $_->{id}, $flds,
  1298. $makemodeljoin);
  1299. push @a, {id => $_->{id}, assemblyitem => 1};
  1300. }
  1301. # copy assemblies to $form->{parts}
  1302. @{ $form->{parts} } = @a;
  1303. }
  1304. @a = ();
  1305. if (($form->{warehouse} ne "") || $form->{l_warehouse}) {
  1306. if ($form->{warehouse} ne "") {
  1307. my ($desc, $var) = split /--/, $form->{warehouse};
  1308. $var = $dbh->quote($var);
  1309. $desc = $dbh->quote($desc);
  1310. $query = qq|
  1311. SELECT SUM(qty) AS onhand,
  1312. $desc AS description
  1313. FROM inventory
  1314. WHERE warehouse_id = $var
  1315. AND parts_id = ?|;
  1316. } else {
  1317. $query = qq|
  1318. SELECT SUM(i.qty) AS onhand,
  1319. w.description AS warehouse
  1320. FROM inventory i
  1321. JOIN warehouse w ON (w.id = i.warehouse_id)
  1322. WHERE i.parts_id = ?
  1323. GROUP BY w.description|;
  1324. }
  1325. $sth = $dbh->prepare($query) || $form->dberror($query);
  1326. for (@{ $form->{parts} }) {
  1327. $sth->execute($_->{id}) || $form->dberror($query);
  1328. if ($form->{warehouse} ne "") {
  1329. $ref = $sth->fetchrow_hashref(NAME_lc);
  1330. if ($ref->{onhand} != 0) {
  1331. $_->{onhand} = $ref->{onhand};
  1332. push @a, $_;
  1333. }
  1334. } else {
  1335. push @a, $_;
  1336. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1337. if ($ref->{onhand} > 0) {
  1338. push @a, $ref;
  1339. }
  1340. }
  1341. }
  1342. $sth->finish;
  1343. }
  1344. @{ $form->{parts} } = @a;
  1345. }
  1346. $dbh->commit;
  1347. }
  1348. sub include_assembly {
  1349. my ($dbh, $myconfig, $form, $id, $flds, $makemodeljoin) = @_;
  1350. $form->{stagger}++;
  1351. if ($form->{stagger} > $form->{pncol}) {
  1352. $form->{pncol} = $form->{stagger};
  1353. }
  1354. $form->{$id} = 1;
  1355. my @a = qw(partnumber description bin);
  1356. if ($form->{sort} eq 'partnumber') {
  1357. $sortorder = "TRUE";
  1358. } else {
  1359. @a = grep !/$form->{sort}/, @a;
  1360. $sortorder = "$form->{sort} $form->{direction}, ". join ',', @a;
  1361. }
  1362. @a = ();
  1363. my $query = qq|
  1364. SELECT $flds
  1365. FROM parts p
  1366. JOIN assembly a ON (a.parts_id = p.id)
  1367. LEFT JOIN partsgroup pg ON (pg.id = p.id)
  1368. LEFT JOIN chart c1 ON (c1.id = p.inventory_accno_id)
  1369. LEFT JOIN chart c2 ON (c2.id = p.income_accno_id)
  1370. LEFT JOIN chart c3 ON (c3.id = p.expense_accno_id)
  1371. $makemodeljoin
  1372. WHERE a.id = ?
  1373. ORDER BY $sortorder|;
  1374. my $sth = $dbh->prepare($query);
  1375. $sth->execute($id) || $form->dberror($query);
  1376. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1377. $ref->{assemblyitem} = 1;
  1378. $ref->{stagger} = $form->{stagger};
  1379. push @a, $ref;
  1380. if ($ref->{assembly} && !$form->{$ref->{id}}) {
  1381. push @a, &include_assembly(
  1382. $dbh, $myconfig, $form, $ref->{id}, $flds,
  1383. $makemodeljoin);
  1384. if ($form->{stagger} > $form->{pncol}) {
  1385. $form->{pncol} = $form->{stagger};
  1386. }
  1387. }
  1388. }
  1389. $sth->finish;
  1390. $form->{$id} = 0;
  1391. $form->{stagger}--;
  1392. @a;
  1393. }
  1394. sub requirements {
  1395. my ($self, $myconfig, $form) = @_;
  1396. my $dbh = $form->{dbh};
  1397. my $null;
  1398. my $var;
  1399. my $ref;
  1400. my $where = qq|p.obsolete = '0'|;
  1401. my $dwhere;
  1402. for (qw(partnumber description)) {
  1403. if ($form->{$_} ne "") {
  1404. $var = $dbh->quote($form->like(lc $form->{$_}));
  1405. $where .= qq| AND lower(p.$_) LIKE $var|;
  1406. }
  1407. }
  1408. if ($form->{partsgroup} ne "") {
  1409. ($null, $var) = split /--/, $form->{partsgroup};
  1410. $var = $dbh->quote($var);
  1411. $where .= qq| AND p.partsgroup_id = $var|;
  1412. }
  1413. # connect to database
  1414. my ($transdatefrom, $transdateto);
  1415. if ($form->{year}) {
  1416. ($transdatefrom, $transdateto)
  1417. = $form->from_to($form->{year}, '01', 12);
  1418. $dwhere = qq| AND a.transdate >= '$transdatefrom'
  1419. AND a.transdate <= '$transdateto'|;
  1420. }
  1421. $query = qq|
  1422. SELECT p.id, p.partnumber, p.description, sum(i.qty) AS qty,
  1423. p.onhand, extract(MONTH FROM a.transdate) AS month,
  1424. '0' AS so, '0' AS po
  1425. FROM invoice i
  1426. JOIN parts p ON (p.id = i.parts_id)
  1427. JOIN ar a ON (a.id = i.trans_id)
  1428. WHERE $where $dwhere AND p.inventory_accno_id > 0
  1429. GROUP BY p.id, p.partnumber, p.description, p.onhand,
  1430. extract(MONTH FROM a.transdate)|;
  1431. my $sth = $dbh->prepare($query);
  1432. $sth->execute || $form->dberror($query);
  1433. my %parts;
  1434. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1435. $parts{$ref->{id}} = $ref;
  1436. }
  1437. $sth->finish;
  1438. my %ofld = ( customer => so, vendor => po );
  1439. for (qw(customer vendor)) {
  1440. $query = qq|
  1441. SELECT p.id, p.partnumber, p.description,
  1442. sum(qty) - sum(ship) AS $ofld{$_}, p.onhand,
  1443. 0 AS month
  1444. FROM orderitems i
  1445. JOIN parts p ON (p.id = i.parts_id)
  1446. JOIN oe a ON (a.id = i.trans_id)
  1447. WHERE $where AND p.inventory_accno_id > 0
  1448. AND p.assembly = '0' AND a.closed = '0'
  1449. AND a.${_}_id > 0
  1450. GROUP BY p.id, p.partnumber, p.description, p.onhand,
  1451. month|;
  1452. $sth = $dbh->prepare($query);
  1453. $sth->execute || $form->dberror($query);
  1454. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1455. if (exists $parts{$ref->{id}}->{$ofld{$_}}) {
  1456. $parts{$ref->{id}}->{$ofld{$_}}
  1457. += $ref->{$ofld{$_}};
  1458. } else {
  1459. $parts{$ref->{id}} = $ref;
  1460. }
  1461. }
  1462. $sth->finish;
  1463. }
  1464. # add assemblies from open sales orders
  1465. $query = qq|
  1466. SELECT DISTINCT a.id AS orderid, b.id, i.qty - i.ship AS qty
  1467. FROM parts p
  1468. JOIN assembly b ON (b.parts_id = p.id)
  1469. JOIN orderitems i ON (i.parts_id = b.id)
  1470. JOIN oe a ON (a.id = i.trans_id)
  1471. WHERE $where
  1472. AND (p.inventory_accno_id > 0 OR p.assembly = '1')
  1473. AND a.closed = '0'|;
  1474. $sth = $dbh->prepare($query);
  1475. $sth->execute || $form->dberror($query);
  1476. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1477. &requirements_assembly(
  1478. $dbh, $form, \%parts, $ref->{id}, $ref->{qty}, $where)
  1479. if $ref->{qty};
  1480. }
  1481. $sth->finish;
  1482. $dbh->commit;
  1483. for (sort { $parts{$a}->{$form->{sort}} cmp $parts{$b}->{$form->{sort}}} keys %parts) {
  1484. push @{ $form->{parts} }, $parts{$_};
  1485. }
  1486. }
  1487. sub requirements_assembly {
  1488. my ($dbh, $form, $parts, $id, $qty, $where) = @_;
  1489. # assemblies
  1490. my $query = qq|
  1491. SELECT p.id, p.partnumber, p.description, a.qty * ? AS so,
  1492. p.onhand, p.assembly, p.partsgroup_id
  1493. FROM assembly a
  1494. JOIN parts p ON (p.id = a.parts_id)
  1495. WHERE $where AND a.id = ? AND p.inventory_accno_id > 0
  1496. UNION
  1497. SELECT p.id, p.partnumber, p.description, a.qty * ? AS so,
  1498. p.onhand, p.assembly, p.partsgroup_id
  1499. FROM assembly a
  1500. JOIN parts p ON (p.id = a.parts_id)
  1501. WHERE a.id = ? AND p.assembly = '1'|;
  1502. my $sth = $dbh->prepare($query);
  1503. $sth->execute($qty, $id, $qty, $id) || $form->dberror($query);
  1504. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  1505. if ($ref->{assembly}) {
  1506. &requirements_assembly(
  1507. $dbh, $form, $parts, $ref->{id}, $ref->{so},
  1508. $where);
  1509. next;
  1510. }
  1511. if (exists $parts->{$ref->{id}}{so}) {
  1512. $parts->{$ref->{id}}{so} += $ref->{so};
  1513. } else {
  1514. $parts->{$ref->{id}} = $ref;
  1515. }
  1516. }
  1517. $sth->finish;
  1518. }
  1519. sub create_links {
  1520. my ($self, $module, $myconfig, $form) = @_;
  1521. # connect to database
  1522. my $dbh = $form->{dbh};
  1523. my $ref;
  1524. my $query = qq|
  1525. SELECT accno, description, link
  1526. FROM chart
  1527. WHERE link LIKE ?
  1528. ORDER BY accno|;
  1529. my $sth = $dbh->prepare($query);
  1530. $sth->execute("%$module%") || $form->dberror($query);
  1531. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1532. foreach my $key (split /:/, $ref->{link}) {
  1533. if ($key =~ /$module/) {
  1534. push @{ $form->{"${module}_links"}{$key} },
  1535. { accno => $ref->{accno},
  1536. description => $ref->{description} };
  1537. }
  1538. }
  1539. }
  1540. $sth->finish;
  1541. if ($form->{item} ne 'assembly') {
  1542. $query = qq|SELECT count(*) FROM vendor|;
  1543. my ($count) = $dbh->selectrow_array($query);
  1544. if ($count < $myconfig->{vclimit}) {
  1545. $query = qq|SELECT id, name FROM vendor ORDER BY name|;
  1546. $sth = $dbh->prepare($query);
  1547. $sth->execute || $form->dberror($query);
  1548. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1549. push @{ $form->{all_vendor} }, $ref;
  1550. }
  1551. $sth->finish;
  1552. }
  1553. }
  1554. # pricegroups, customers
  1555. $query = qq|SELECT count(*) FROM customer|;
  1556. ($count) = $dbh->selectrow_array($query);
  1557. if ($count < $myconfig->{vclimit}) {
  1558. $query = qq|SELECT id, name FROM customer ORDER BY name|;
  1559. $sth = $dbh->prepare($query);
  1560. $sth->execute || $form->dberror($query);
  1561. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1562. push @{ $form->{all_customer} }, $ref;
  1563. }
  1564. $sth->finish;
  1565. }
  1566. $query = qq|SELECT id, pricegroup FROM pricegroup ORDER BY pricegroup|;
  1567. $sth = $dbh->prepare($query);
  1568. $sth->execute || $form->dberror($query);
  1569. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1570. push @{ $form->{all_pricegroup} }, $ref;
  1571. }
  1572. $sth->finish;
  1573. if ($form->{id}) {
  1574. $query = qq|
  1575. SELECT value FROM defaults
  1576. WHERE setting_key = 'weightunit'|;
  1577. ($form->{weightunit}) = $dbh->selectrow_array($query);
  1578. $query = qq|
  1579. SELECT value FROM defaults
  1580. WHERE setting_key = 'curr'|;
  1581. ($form->{currencies}) = $dbh->selectrow_array($query);
  1582. } else {
  1583. # Dieter: FIXME left joins not working
  1584. $query = qq|
  1585. SELECT (SELECT value FROM defaults
  1586. WHERE setting_key = 'weightunit')
  1587. AS weightunit, current_date AS priceupdate,
  1588. (SELECT value FROM defaults
  1589. WHERE setting_key = 'curr') AS currencies,
  1590. c1.accno AS inventory_accno,
  1591. c1.description AS inventory_description,
  1592. c2.accno AS income_accno,
  1593. c2.description AS income_description,
  1594. c3.accno AS expense_accno,
  1595. c3.description AS expense_description
  1596. FROM chart c1, chart c2, chart c3
  1597. WHERE c1.id IN (SELECT value FROM defaults
  1598. WHERE setting_key = 'inventory_accno_id')
  1599. AND c2.id IN (SELECT value FROM defaults
  1600. WHERE setting_key = 'income_accno_id')
  1601. AND c3.id IN (SELECT value FROM defaults
  1602. WHERE setting_key
  1603. = 'expense_accno_id')|;
  1604. $sth = $dbh->prepare($query);
  1605. $sth->execute || $form->dberror($query);
  1606. $ref = $sth->fetchrow_hashref(NAME_lc);
  1607. for (qw(weightunit priceupdate currencies)) {
  1608. $form->{$_} = $ref->{$_};
  1609. }
  1610. # setup accno hash, {amount} is used in create_links
  1611. for (qw(inventory income expense)) {
  1612. $form->{amount}{"IC_$_"}
  1613. = {
  1614. accno => $ref->{"${_}_accno"},
  1615. description => $ref->{"${_}_description"}
  1616. };
  1617. }
  1618. $sth->finish;
  1619. }
  1620. $dbh->commit;
  1621. }
  1622. sub get_warehouses {
  1623. my ($self, $myconfig, $form) = @_;
  1624. my $dbh = $form->{dbh};
  1625. my $query = qq|SELECT id, description FROM warehouse|;
  1626. my $sth = $dbh->prepare($query);
  1627. $sth->execute || $form->dberror($query);
  1628. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  1629. push @{ $form->{all_warehouse} }, $ref;
  1630. }
  1631. $sth->finish;
  1632. $dbh->commit;
  1633. }
  1634. 1;