summaryrefslogtreecommitdiff
path: root/LedgerSMB/OE.pm
blob: f8759cc8b72a724f747e312b39e0e4400c742ced (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) 2001
  18. #
  19. # Author: DWS Systems Inc.
  20. # Web: http://www.sql-ledger.org
  21. #
  22. # Contributors:
  23. #
  24. #======================================================================
  25. #
  26. # This file has undergone PARTIAL (30%) whitespace cleanup To line 638
  27. #
  28. #======================================================================
  29. #
  30. # Order entry module
  31. # Quotation
  32. #
  33. #======================================================================
  34. package OE;
  35. sub transactions {
  36. my ($self, $myconfig, $form) = @_;
  37. # connect to database
  38. my $dbh = $form->{dbh};
  39. my $query;
  40. my $null;
  41. my $var;
  42. my $ordnumber = 'ordnumber';
  43. my $quotation = '0';
  44. my $department;
  45. my $rate = ($form->{vc} eq 'customer') ? 'buy' : 'sell';
  46. ($form->{transdatefrom}, $form->{transdateto}) =
  47. $form->from_to($form->{year}, $form->{month}, $form->{interval})
  48. if $form->{year} && $form->{month};
  49. if ($form->{type} =~ /_quotation$/) {
  50. $quotation = '1';
  51. $ordnumber = 'quonumber';
  52. }
  53. my $number = $form->like(lc $form->{$ordnumber});
  54. my $name = $form->like(lc $form->{$form->{vc}});
  55. my @dptargs = ();
  56. for (qw(department employee)) {
  57. if ($form->{$_}) {
  58. ($null, $var) = split /--/, $form->{$_};
  59. $department .= " AND o.${_}_id = ?";
  60. push @dptargs, $var;
  61. }
  62. }
  63. if ($form->{vc} == 'customer'){ # Sanitize $form->{vc}
  64. $form->{vc} = 'customer';
  65. } else {
  66. $form->{vc} = 'vendor';
  67. }
  68. my $query = qq|
  69. SELECT o.id, o.ordnumber, o.transdate, o.reqdate,
  70. o.amount, ct.name, o.netamount, o.$form->{vc}_id,
  71. ex.$rate AS exchangerate, o.closed, o.quonumber,
  72. o.shippingpoint, o.shipvia, e.name AS employee,
  73. m.name AS manager, o.curr, o.ponumber
  74. FROM oe o
  75. JOIN $form->{vc} ct ON (o.$form->{vc}_id = ct.id)
  76. LEFT JOIN employee e ON (o.employee_id = e.id)
  77. LEFT JOIN employee m ON (e.managerid = m.id)
  78. LEFT JOIN exchangerate ex
  79. ON (ex.curr = o.curr AND ex.transdate = o.transdate)
  80. WHERE o.quotation = ?
  81. $department|;
  82. my @queryargs = @dptargs;
  83. unshift @queryargs, $quotation;
  84. my %ordinal = (
  85. id => 1,
  86. ordnumber => 2,
  87. transdate => 3,
  88. reqdate => 4,
  89. name => 6,
  90. quonumber => 11,
  91. shipvia => 13,
  92. employee => 14,
  93. manager => 15,
  94. curr => 16,
  95. ponumber => 17);
  96. my @a = (transdate, $ordnumber, name);
  97. push @a, "employee" if $form->{l_employee};
  98. if ($form->{type} !~ /(ship|receive)_order/) {
  99. push @a, "manager" if $form->{l_manager};
  100. }
  101. my $sortorder = $form->sort_order(\@a, \%ordinal);
  102. # build query if type eq (ship|receive)_order
  103. if ($form->{type} =~ /(ship|receive)_order/) {
  104. my ($warehouse, $warehouse_id) = split /--/, $form->{warehouse};
  105. $query = qq|
  106. SELECT DISTINCT o.id, o.ordnumber, o.transdate,
  107. o.reqdate, o.amount, ct.name, o.netamount,
  108. o.$form->{vc}_id, ex.$rate AS exchangerate,
  109. o.closed, o.quonumber, o.shippingpoint,
  110. o.shipvia, e.name AS employee, o.curr,
  111. o.ponumber
  112. FROM oe o
  113. JOIN $form->{vc} ct ON (o.$form->{vc}_id = ct.id)
  114. JOIN orderitems oi ON (oi.trans_id = o.id)
  115. JOIN parts p ON (p.id = oi.parts_id)|;
  116. if ($warehouse_id && $form->{type} eq 'ship_order') {
  117. $query .= qq|
  118. JOIN inventory i ON (oi.parts_id = i.parts_id)
  119. |;
  120. }
  121. $query .= qq|
  122. LEFT JOIN employee e ON (o.employee_id = e.id)
  123. LEFT JOIN exchangerate ex
  124. ON (ex.curr = o.curr
  125. AND ex.transdate = o.transdate)
  126. WHERE o.quotation = '0'
  127. AND (p.inventory_accno_id > 0 OR p.assembly = '1')
  128. AND oi.qty != oi.ship
  129. $department|;
  130. @queryargs = @dptargs; #reset @queryargs
  131. if ($warehouse_id && $form->{type} eq 'ship_order') {
  132. $query .= qq|
  133. AND i.warehouse_id = ?
  134. AND (
  135. SELECT SUM(i.qty)
  136. FROM inventory i
  137. WHERE oi.parts_id = i.parts_id
  138. AND i.warehouse_id = ?
  139. ) > 0|;
  140. push(@queryargs, $warehouse_id, $warehouse_id);
  141. }
  142. }
  143. if ($form->{"$form->{vc}_id"}) {
  144. $query .= qq| AND o.$form->{vc}_id = $form->{"$form->{vc}_id"}|;
  145. } elsif ($form->{$form->{vc}} ne "") {
  146. $query .= " AND lower(ct.name) LIKE ?";
  147. push @queryargs, $name;
  148. }
  149. if ($form->{$ordnumber} ne "") {
  150. $query .= " AND lower(?) LIKE ?";
  151. push @queryargs, $ordnumber, $number;
  152. $form->{open} = 1;
  153. $form->{closed} = 1;
  154. }
  155. if ($form->{ponumber} ne "") {
  156. $query .= " AND lower(ponumber) LIKE ?";
  157. push @queryargs, $form->{ponumber};
  158. }
  159. if (!$form->{open} && !$form->{closed}) {
  160. $query .= " AND o.id = 0";
  161. } elsif (!($form->{open} && $form->{closed})) {
  162. $query .= ($form->{open}) ?
  163. " AND o.closed = '0'" : " AND o.closed = '1'";
  164. }
  165. if ($form->{shipvia} ne "") {
  166. $var = $form->like(lc $form->{shipvia});
  167. $query .= " AND lower(o.shipvia) LIKE ?";
  168. push @queryargs, $var;
  169. }
  170. if ($form->{description} ne "") {
  171. $var = $form->like(lc $form->{description});
  172. $query .= " AND o.id IN (SELECT DISTINCT trans_id
  173. FROM orderitems
  174. WHERE lower(description) LIKE '$var')";
  175. push @queryargs, $var;
  176. }
  177. if ($form->{transdatefrom}) {
  178. $query .= " AND o.transdate >= ?";
  179. push @queryargs, $form->{transdatefrom};
  180. }
  181. if ($form->{transdateto}) {
  182. $query .= " AND o.transdate <= ?";
  183. push @queryargs, $form->{transdateto};
  184. }
  185. $query .= " ORDER by $sortorder";
  186. my $sth = $dbh->prepare($query);
  187. $sth->execute(@queryargs) || $form->dberror($query);
  188. my %oid = ();
  189. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  190. $ref->{exchangerate} = 1 unless $ref->{exchangerate};
  191. if ($ref->{id} != $oid{id}{$ref->{id}}) {
  192. push @{ $form->{OE} }, $ref;
  193. $oid{vc}{$ref->{curr}}{$ref->{"$form->{vc}_id"}}++;
  194. }
  195. $oid{id}{$ref->{id}} = $ref->{id};
  196. }
  197. $sth->finish;
  198. $dbh->commit;
  199. if ($form->{type} =~ /^consolidate_/) {
  200. @a = ();
  201. foreach $ref (@{ $form->{OE} }) {
  202. push @a, $ref if $oid{vc}{$ref->{curr}}
  203. {$ref->{"$form->{vc}_id"}} > 1;
  204. }
  205. @{ $form->{OE} } = @a;
  206. }
  207. }
  208. sub save {
  209. my ($self, $myconfig, $form) = @_;
  210. # connect to database, turn off autocommit
  211. my $dbh = $form->{dbh};
  212. my $quotation;
  213. my $ordnumber;
  214. my $numberfld;
  215. if ($form->{type} =~ /_order$/) {
  216. $quotation = "0";
  217. $ordnumber = "ordnumber";
  218. $numberfld = ($form->{vc} eq 'customer') ? "sonumber" :
  219. "ponumber";
  220. } else {
  221. $quotation = "1";
  222. $ordnumber = "quonumber";
  223. $numberfld = ($form->{vc} eq 'customer') ? "sqnumber" :
  224. "rfqnumber";
  225. }
  226. $form->{ordnumber} = $form->update_defaults(
  227. $myconfig, $numberfld, $dbh)
  228. unless $form->{ordnumber};
  229. my $query;
  230. my $sth;
  231. my $null;
  232. my $exchangerate = 0;
  233. ($null, $form->{employee_id}) = split /--/, $form->{employee};
  234. if (! $form->{employee_id}) {
  235. ($form->{employee}, $form->{employee_id}) =
  236. $form->get_employee($dbh);
  237. $form->{employee} = "$form->{employee}--$form->{employee_id}";
  238. }
  239. my $ml = ($form->{type} eq 'sales_order') ? 1 : -1;
  240. $query = qq|
  241. SELECT p.assembly, p.project_id
  242. FROM parts p WHERE p.id = ?|;
  243. my $pth = $dbh->prepare($query) || $form->dberror($query);
  244. if ($form->{id}) {
  245. $query = qq|SELECT id FROM oe WHERE id = $form->{id}|;
  246. if ($dbh->selectrow_array($query)) {
  247. &adj_onhand($dbh, $form, $ml)
  248. if $form->{type} =~ /_order$/;
  249. $query = qq|DELETE FROM orderitems WHERE trans_id = ?|;
  250. $sth = $dbh->prepare($query);
  251. $sth->execute($form->{id}) || $form->dberror($query);
  252. $query = qq|DELETE FROM shipto WHERE trans_id = ?|;
  253. $sth = $dbh->prepare($query);
  254. $sth->execute($form->{id}) || $form->dberror($query);
  255. } else {
  256. $query = qq|INSERT INTO oe (id) VALUES (?)|;
  257. $sth = $dbh->prepare($query);
  258. $sth->execute($form->{id}) || $form->dberror($query);
  259. }
  260. }
  261. my $did_insert = 0;
  262. if (! $form->{id}) {
  263. my $uid = localtime;
  264. $uid .= "$$";
  265. $query = qq|
  266. INSERT INTO oe (ordnumber, employee_id)
  267. VALUES ('$uid', $form->{employee_id})|;
  268. $dbh->do($query) || $form->dberror($query);
  269. $query = qq|SELECT id FROM oe WHERE ordnumber = '$uid'|;
  270. $sth = $dbh->prepare($query);
  271. $sth->execute || $form->dberror($query);
  272. ($form->{id}) = $sth->fetchrow_array;
  273. $sth->finish;
  274. @queries = $form->get_custom_queries('oe', 'INSERT');
  275. for (@queries){
  276. $query = shift (@{$_});
  277. $sth = $dbh->prepare($query)
  278. || $form->db_error($query);
  279. $sth->execute(@{$_}, $form->{id})
  280. || $form->dberror($query);;
  281. $sth->finish;
  282. $did_insert = 1;
  283. }
  284. }
  285. my $amount;
  286. my $linetotal;
  287. my $discount;
  288. my $project_id;
  289. my $taxrate;
  290. my $taxamount;
  291. my $fxsellprice;
  292. my %taxbase;
  293. my @taxaccounts;
  294. my %taxaccounts;
  295. my $netamount = 0;
  296. my $rowcount = $form->{rowcount} - 1;
  297. for my $i (1 .. $rowcount) {
  298. $form->db_prepare_vars("orderitems_id_$i", "id_$i",
  299. "description_$i", "project_id_$i", "ship_$i");
  300. for (qw(qty ship)) {
  301. $form->{"${_}_$i"} = $form->parse_amount(
  302. $myconfig, $form->{"${_}_$i"}
  303. );
  304. }
  305. $form->{"discount_$i"} = $form->parse_amount(
  306. $myconfig, $form->{"discount_$i"}
  307. ) / 100;
  308. $form->{"sellprice_$i"} = $form->parse_amount(
  309. $myconfig, $form->{"sellprice_$i"}
  310. );
  311. if ($form->{"qty_$i"}) {
  312. $pth->execute($form->{"id_$i"});
  313. $ref = $pth->fetchrow_hashref(NAME_lc);
  314. for (keys %$ref) { $form->{"${_}_$i"} = $ref->{$_} }
  315. $pth->finish;
  316. $fxsellprice = $form->{"sellprice_$i"};
  317. my ($dec) = ($form->{"sellprice_$i"} =~ /\.(\d+)/);
  318. $dec = length $dec;
  319. my $decimalplaces = ($dec > 2) ? $dec : 2;
  320. $discount = $form->round_amount(
  321. $form->{"sellprice_$i"} *
  322. $form->{"discount_$i"},
  323. $decimalplaces
  324. );
  325. $form->{"sellprice_$i"} = $form->round_amount(
  326. $form->{"sellprice_$i"} - $discount,
  327. $decimalplaces
  328. );
  329. $linetotal = $form->round_amount(
  330. $form->{"sellprice_$i"} * $form->{"qty_$i"}, 2
  331. );
  332. @taxaccounts = split / /, $form->{"taxaccounts_$i"};
  333. $taxrate = 0;
  334. $taxdiff = 0;
  335. for (@taxaccounts) { $taxrate += $form->{"${_}_rate"} }
  336. if ($form->{taxincluded}) {
  337. $taxamount = $linetotal * $taxrate
  338. / (1 + $taxrate);
  339. $taxbase = $linetotal - $taxamount;
  340. # we are not keeping a natural price,
  341. # do not round
  342. $form->{"sellprice_$i"} =
  343. $form->{"sellprice_$i"}
  344. * (1 / (1 + $taxrate));
  345. } else {
  346. $taxamount = $linetotal * $taxrate;
  347. $taxbase = $linetotal;
  348. }
  349. if (@taxaccounts && $form->round_amount($taxamount, 2)
  350. == 0) {
  351. if ($form->{taxincluded}) {
  352. foreach $item (@taxaccounts) {
  353. $taxamount =
  354. $form->round_amount(
  355. $linetotal
  356. * $form->{"${item}_rate"}
  357. / (1 + abs(
  358. $form->{"${item}_rate"}
  359. )), 2
  360. );
  361. $taxaccounts{$item} +=
  362. $taxamount;
  363. $taxdiff += $taxamount;
  364. $taxbase{$item} += $taxbase;
  365. }
  366. $taxaccounts{$taxaccounts[0]}
  367. += $taxdiff;
  368. } else {
  369. foreach $item (@taxaccounts) {
  370. $taxaccounts{$item} +=
  371. $linetotal *
  372. $form->{"${item}_rate"};
  373. $taxbase{$item} += $taxbase;
  374. }
  375. }
  376. } else {
  377. foreach $item (@taxaccounts) {
  378. $taxaccounts{$item} +=
  379. $taxamount *
  380. $form->{"${item}_rate"} /
  381. $taxrate;
  382. $taxbase{$item} += $taxbase;
  383. }
  384. }
  385. $netamount += $form->{"sellprice_$i"}
  386. * $form->{"qty_$i"};
  387. if ($form->{"projectnumber_$i"} ne "") {
  388. ($null, $project_id)
  389. = split /--/,
  390. $form->{"projectnumber_$i"};
  391. }
  392. $project_id = $form->{"project_id_$i"}
  393. if $form->{"project_id_$i"};
  394. if (!$form->{"reqdate_$i"}){
  395. $form->{"reqdate_$i"} = undef;
  396. }
  397. @queryargs = ();
  398. # save detail record in orderitems table
  399. $query = qq|INSERT INTO orderitems (|;
  400. if ($form->{"orderitems_id_$i"}){
  401. $query .= "id, ";
  402. }
  403. $query .= qq|
  404. trans_id, parts_id, description, qty, sellprice,
  405. discount, unit, reqdate, project_id, ship,
  406. serialnumber, notes)
  407. VALUES (|;
  408. if ($form->{"orderitems_id_$i"}){
  409. $query .= "?, ";
  410. push @queryargs, $form->{"orderitems_id_$i"};
  411. }
  412. $query .= qq| ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)|;
  413. $sth = $dbh->prepare($query);
  414. push (@queryargs,
  415. $form->{id}, $form->{"id_$i"},
  416. $form->{"description_$i"}, $form->{"qty_$i"},
  417. $fxsellprice, $form->{"discount_$i"},
  418. $form->{"unit_$i"}, $form->{"reqdate_$i"},
  419. $project_id, $form->{"ship_$i"},
  420. $form->{"serialnumber_$i"},
  421. $form->{"notes_$i"});
  422. $sth->execute(@queryargs) || $form->dberror($query);
  423. $form->{"sellprice_$i"} = $fxsellprice;
  424. }
  425. $form->{"discount_$i"} *= 100;
  426. }
  427. # set values which could be empty
  428. for (qw(vendor_id customer_id taxincluded closed quotation))
  429. { $form->{$_} *= 1 }
  430. # add up the tax
  431. my $tax = 0;
  432. for (keys %taxaccounts) { $tax += $taxaccounts{$_} }
  433. $amount = $form->round_amount($netamount + $tax, 2);
  434. $netamount = $form->round_amount($netamount, 2);
  435. if ($form->{currency} eq $form->{defaultcurrency}) {
  436. $form->{exchangerate} = 1;
  437. } else {
  438. $exchangerate = $form->check_exchangerate(
  439. $myconfig, $form->{currency}, $form->{transdate},
  440. ($form->{vc} eq 'customer') ? 'buy' : 'sell');
  441. }
  442. $form->{exchangerate} = ($exchangerate) ? $exchangerate :
  443. $form->parse_amount($myconfig, $form->{exchangerate});
  444. ($null, $form->{department_id}) = split(/--/, $form->{department});
  445. for (qw(department_id terms)) { $form->{$_} *= 1 }
  446. # save OE record
  447. $query = qq|
  448. UPDATE oe set
  449. ordnumber = ?,
  450. quonumber = ?,
  451. transdate = ?,
  452. vendor_id = ?,
  453. customer_id = ?,
  454. amount = ?,
  455. netamount = ?,
  456. reqdate = ?,
  457. taxincluded = ?,
  458. shippingpoint = ?,
  459. shipvia = ?,
  460. notes = ?,
  461. intnotes = ?,
  462. curr = ?,
  463. closed = ?,
  464. quotation = ?,
  465. department_id = ?,
  466. employee_id = ?,
  467. language_code = ?,
  468. ponumber = ?,
  469. terms = ?
  470. WHERE id = ?|;
  471. $form->db_prepare_vars("quonumber", "transdate", "vendor_id",
  472. "customer_id", "reqdate", "taxincluded", "shippingpoint",
  473. "shipvia", "currency", "closed", "department_id",
  474. "employee_id", "language_code", "ponumber", "terms");
  475. if (!$form->{reqdate}){
  476. $form->{reqdate} = undef;
  477. }
  478. @queryargs = ($form->{ordnumber},
  479. $form->{quonumber},
  480. $form->{transdate},
  481. $form->{vendor_id},
  482. $form->{customer_id},
  483. $amount,
  484. $netamount,
  485. $form->{reqdate},
  486. $form->{taxincluded},
  487. $form->{shippingpoint},
  488. $form->{shipvia},
  489. $form->{notes},
  490. $form->{intnotes},
  491. $form->{currency},
  492. $form->{closed},
  493. $quotation,
  494. $form->{department_id},
  495. $form->{employee_id},
  496. $form->{language_code},
  497. $form->{ponumber},
  498. $form->{terms},
  499. $form->{id});
  500. $sth = $dbh->prepare($query);
  501. $sth->execute(@queryargs) || $form->dberror($query);
  502. if (!$did_insert){
  503. @queries = $form->get_custom_queries('oe', 'UPDATE');
  504. for (@queries){
  505. my $query = shift @{$_};
  506. $sth = $dbh->prepare($query);
  507. $sth->execute (@{$_}, $form->{id});
  508. $sth->finish;
  509. }
  510. }
  511. $form->{ordtotal} = $amount;
  512. # add shipto
  513. $form->{name} = $form->{$form->{vc}};
  514. $form->{name} =~ s/--$form->{"$form->{vc}_id"}//;
  515. $form->add_shipto($dbh, $form->{id});
  516. # save printed, emailed, queued
  517. $form->save_status($dbh);
  518. if (($form->{currency} ne $form->{defaultcurrency}) && !$exchangerate) {
  519. if ($form->{vc} eq 'customer') {
  520. $form->update_exchangerate(
  521. $dbh,
  522. $form->{currency},
  523. $form->{transdate},
  524. $form->{exchangerate},
  525. 0);
  526. }
  527. if ($form->{vc} eq 'vendor') {
  528. $form->update_exchangerate(
  529. $dbh,
  530. $form->{currency},
  531. $form->{transdate},
  532. 0,
  533. $form->{exchangerate});
  534. }
  535. }
  536. if ($form->{type} =~ /_order$/) {
  537. # adjust onhand
  538. &adj_onhand($dbh, $form, $ml * -1);
  539. &adj_inventory($dbh, $myconfig, $form);
  540. }
  541. my %audittrail = (
  542. tablename => 'oe',
  543. reference => ($form->{type} =~ /_order$/)
  544. ? $form->{ordnumber} : $form->{quonumber},
  545. formname => $form->{type},
  546. action => 'saved',
  547. id => $form->{id} );
  548. $form->audittrail($dbh, "", \%audittrail);
  549. $form->save_recurring($dbh, $myconfig);
  550. my $rc = $dbh->commit;
  551. $rc;
  552. }
  553. sub delete {
  554. my ($self, $myconfig, $form, $spool) = @_;
  555. # connect to database
  556. my $dbh = $form->{dbh};
  557. # delete spool files
  558. my $query = qq|
  559. SELECT spoolfile FROM status
  560. WHERE trans_id = ?
  561. AND spoolfile IS NOT NULL|;
  562. $sth = $dbh->prepare($query);
  563. $sth->execute($form->{id}) || $form->dberror($query);
  564. my $spoolfile;
  565. my @spoolfiles = ();
  566. while (($spoolfile) = $sth->fetchrow_array) {
  567. push @spoolfiles, $spoolfile;
  568. }
  569. $sth->finish;
  570. $query = qq|
  571. SELECT o.parts_id, o.ship, p.inventory_accno_id, p.assembly
  572. FROM orderitems o
  573. JOIN parts p ON (p.id = o.parts_id)
  574. WHERE trans_id = ?|;
  575. $sth = $dbh->prepare($query);
  576. $sth->execute($form->{id}) || $form->dberror($query);
  577. if ($form->{type} =~ /_order$/) {
  578. $ml = ($form->{type} eq 'purchase_order') ? -1 : 1;
  579. while (my ($id, $ship, $inv, $assembly)
  580. = $sth->fetchrow_array) {
  581. $form->update_balance(
  582. $dbh,
  583. "parts",
  584. "onhand",
  585. "id = $id",
  586. $ship * $ml)
  587. if ($inv || $assembly);
  588. }
  589. }
  590. $sth->finish;
  591. # delete inventory
  592. $query = qq|DELETE FROM inventory WHERE trans_id = ?|;
  593. $sth = $dbh->prepare($query);
  594. $sth->execute($form->{id}) || $form->dberror($query);
  595. $sth->finish;
  596. # delete status entries
  597. $query = qq|DELETE FROM status WHERE trans_id = ?|;
  598. $sth = $dbh->prepare($query);
  599. $sth->execute($form->{id}) || $form->dberror($query);
  600. $sth->finish;
  601. # delete OE record
  602. $query = qq|DELETE FROM oe WHERE id = ?|;
  603. $sth = $dbh->prepare($query);
  604. $sth->execute($form->{id}) || $form->dberror($query);
  605. $sth->finish;
  606. # delete individual entries
  607. $query = qq|DELETE FROM orderitems WHERE trans_id = ?|;
  608. $sth->finish;
  609. $query = qq|DELETE FROM shipto WHERE trans_id = ?|;
  610. $sth = $dbh->prepare($query);
  611. $sth->execute($form->{id}) || $form->dberror($query);
  612. $sth->finish;
  613. my %audittrail = (
  614. tablename => 'oe',
  615. reference => ($form->{type} =~ /_order$/)
  616. ? $form->{ordnumber} : $form->{quonumber},
  617. formname => $form->{type},
  618. action => 'deleted',
  619. id => $form->{id} );
  620. $form->audittrail($dbh, "", \%audittrail);
  621. my $rc = $dbh->commit;
  622. $dbh->disconnect;
  623. if ($rc) {
  624. foreach $spoolfile (@spoolfiles) {
  625. unlink "$spool/$spoolfile" if $spoolfile;
  626. }
  627. }
  628. $rc;
  629. }
  630. sub retrieve {
  631. my ($self, $myconfig, $form) = @_;
  632. # connect to database
  633. my $dbh = $form->dbconnect($myconfig);
  634. my $query;
  635. my $sth;
  636. my $var;
  637. my $ref;
  638. $query = qq|SELECT curr, current_date
  639. FROM defaults|;
  640. ($form->{currencies}, $form->{transdate}) = $dbh->selectrow_array($query);
  641. if ($form->{id}) {
  642. # retrieve order
  643. $query = qq|SELECT o.ordnumber, o.transdate, o.reqdate, o.terms,
  644. o.taxincluded, o.shippingpoint, o.shipvia, o.notes, o.intnotes,
  645. o.curr AS currency, e.name AS employee, o.employee_id,
  646. o.$form->{vc}_id, vc.name AS $form->{vc}, o.amount AS invtotal,
  647. o.closed, o.reqdate, o.quonumber, o.department_id,
  648. d.description AS department, o.language_code, o.ponumber
  649. FROM oe o
  650. JOIN $form->{vc} vc ON (o.$form->{vc}_id = vc.id)
  651. LEFT JOIN employee e ON (o.employee_id = e.id)
  652. LEFT JOIN department d ON (o.department_id = d.id)
  653. WHERE o.id = $form->{id}|;
  654. $sth = $dbh->prepare($query);
  655. $sth->execute || $form->dberror($query);
  656. $ref = $sth->fetchrow_hashref(NAME_lc);
  657. for (keys %$ref) { $form->{$_} = $ref->{$_} }
  658. $sth->finish;
  659. $query = qq|SELECT * FROM shipto
  660. WHERE trans_id = $form->{id}|;
  661. $sth = $dbh->prepare($query);
  662. $sth->execute || $form->dberror($query);
  663. $ref = $sth->fetchrow_hashref(NAME_lc);
  664. for (keys %$ref) { $form->{$_} = $ref->{$_} }
  665. $sth->finish;
  666. # get printed, emailed and queued
  667. $query = qq|SELECT s.printed, s.emailed, s.spoolfile, s.formname
  668. FROM status s
  669. WHERE s.trans_id = $form->{id}|;
  670. $sth = $dbh->prepare($query);
  671. $sth->execute || $form->dberror($query);
  672. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  673. $form->{printed} .= "$ref->{formname} " if $ref->{printed};
  674. $form->{emailed} .= "$ref->{formname} " if $ref->{emailed};
  675. $form->{queued} .= "$ref->{formname} $ref->{spoolfile} " if $ref->{spoolfile};
  676. }
  677. $sth->finish;
  678. for (qw(printed emailed queued)) { $form->{$_} =~ s/ +$//g }
  679. # retrieve individual items
  680. $query = qq|SELECT o.id AS orderitems_id,
  681. p.partnumber, p.assembly, o.description, o.qty,
  682. o.sellprice, o.parts_id AS id, o.unit, o.discount, p.bin,
  683. o.reqdate, o.project_id, o.ship, o.serialnumber, o.notes,
  684. pr.projectnumber,
  685. pg.partsgroup, p.partsgroup_id, p.partnumber AS sku,
  686. p.listprice, p.lastcost, p.weight, p.onhand,
  687. p.inventory_accno_id, p.income_accno_id, p.expense_accno_id,
  688. t.description AS partsgrouptranslation
  689. FROM orderitems o
  690. JOIN parts p ON (o.parts_id = p.id)
  691. LEFT JOIN project pr ON (o.project_id = pr.id)
  692. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  693. LEFT JOIN translation t ON (t.trans_id = p.partsgroup_id AND t.language_code = '$form->{language_code}')
  694. WHERE o.trans_id = $form->{id}
  695. ORDER BY o.id|;
  696. $sth = $dbh->prepare($query);
  697. $sth->execute || $form->dberror($query);
  698. # foreign exchange rates
  699. &exchangerate_defaults($dbh, $form);
  700. # query for price matrix
  701. my $pmh = &price_matrix_query($dbh, $form);
  702. # taxes
  703. $query = qq|SELECT c.accno
  704. FROM chart c
  705. JOIN partstax pt ON (pt.chart_id = c.id)
  706. WHERE pt.parts_id = ?|;
  707. my $tth = $dbh->prepare($query) || $form->dberror($query);
  708. my $taxrate;
  709. my $ptref;
  710. my $sellprice;
  711. my $listprice;
  712. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  713. ($decimalplaces) = ($ref->{sellprice} =~ /\.(\d+)/);
  714. $decimalplaces = length $decimalplaces;
  715. $decimalplaces = ($decimalplaces > 2) ? $decimalplaces : 2;
  716. $tth->execute($ref->{id});
  717. $ref->{taxaccounts} = "";
  718. $taxrate = 0;
  719. while ($ptref = $tth->fetchrow_hashref(NAME_lc)) {
  720. $ref->{taxaccounts} .= "$ptref->{accno} ";
  721. $taxrate += $form->{"$ptref->{accno}_rate"};
  722. }
  723. $tth->finish;
  724. chop $ref->{taxaccounts};
  725. # preserve price
  726. $sellprice = $ref->{sellprice};
  727. # multiply by exchangerate
  728. $ref->{sellprice} = $form->round_amount($ref->{sellprice} * $form->{$form->{currency}}, $decimalplaces);
  729. for (qw(listprice lastcost)) { $ref->{$_} = $form->round_amount($ref->{$_} / $form->{$form->{currency}}, $decimalplaces) }
  730. # partnumber and price matrix
  731. &price_matrix($pmh, $ref, $form->{transdate}, $decimalplaces, $form, $myconfig);
  732. $ref->{sellprice} = $sellprice;
  733. $ref->{partsgroup} = $ref->{partsgrouptranslation} if $ref->{partsgrouptranslation};
  734. push @{ $form->{form_details} }, $ref;
  735. }
  736. $sth->finish;
  737. # get recurring transaction
  738. $form->get_recurring($dbh);
  739. @queries = $form->get_custom_queries('oe', 'SELECT');
  740. for (@queries){
  741. $query = shift @{$_};
  742. $sth = $form->{dbh}->prepare($query);
  743. $sth->execute($form->{id});
  744. $ref = $sth->fetchrow_hashref(NAME_lc);
  745. for (keys %{$ref}){
  746. $form->{$_} = $ref->{$_};
  747. }
  748. }
  749. $form->{dbh}->commit;
  750. } else {
  751. # get last name used
  752. $form->lastname_used($myconfig, $dbh, $form->{vc}) unless $form->{"$form->{vc}_id"};
  753. delete $form->{notes};
  754. }
  755. $dbh->disconnect;
  756. }
  757. sub price_matrix_query {
  758. my ($dbh, $form) = @_;
  759. my $query;
  760. my $sth;
  761. if ($form->{customer_id}) {
  762. $query = qq|SELECT p.id AS parts_id, 0 AS customer_id, 0 AS pricegroup_id,
  763. 0 AS pricebreak, p.sellprice, NULL AS validfrom, NULL AS validto,
  764. '$form->{defaultcurrency}' AS curr, '' AS pricegroup
  765. FROM parts p
  766. WHERE p.id = ?
  767. UNION
  768. SELECT p.*, g.pricegroup
  769. FROM partscustomer p
  770. LEFT JOIN pricegroup g ON (g.id = p.pricegroup_id)
  771. WHERE p.parts_id = ?
  772. AND p.customer_id = $form->{customer_id}
  773. UNION
  774. SELECT p.*, g.pricegroup
  775. FROM partscustomer p
  776. LEFT JOIN pricegroup g ON (g.id = p.pricegroup_id)
  777. JOIN customer c ON (c.pricegroup_id = g.id)
  778. WHERE p.parts_id = ?
  779. AND c.id = $form->{customer_id}
  780. UNION
  781. SELECT p.*, '' AS pricegroup
  782. FROM partscustomer p
  783. WHERE p.customer_id = 0
  784. AND p.pricegroup_id = 0
  785. AND p.parts_id = ?
  786. ORDER BY customer_id DESC, pricegroup_id DESC, pricebreak
  787. |;
  788. $sth = $dbh->prepare($query) || $form->dberror($query);
  789. }
  790. if ($form->{vendor_id}) {
  791. # price matrix and vendor's partnumber
  792. $query = qq|SELECT partnumber
  793. FROM partsvendor
  794. WHERE parts_id = ?
  795. AND vendor_id = $form->{vendor_id}|;
  796. $sth = $dbh->prepare($query) || $form->dberror($query);
  797. }
  798. $sth;
  799. }
  800. sub price_matrix {
  801. my ($pmh, $ref, $transdate, $decimalplaces, $form, $myconfig) = @_;
  802. $ref->{pricematrix} = "";
  803. my $customerprice;
  804. my $pricegroupprice;
  805. my $sellprice;
  806. my $mref;
  807. my %p = ();
  808. # depends if this is a customer or vendor
  809. if ($form->{customer_id}) {
  810. $pmh->execute($ref->{id}, $ref->{id}, $ref->{id}, $ref->{id});
  811. while ($mref = $pmh->fetchrow_hashref(NAME_lc)) {
  812. # check date
  813. if ($mref->{validfrom}) {
  814. next if $transdate < $form->datetonum($myconfig, $mref->{validfrom});
  815. }
  816. if ($mref->{validto}) {
  817. next if $transdate > $form->datetonum($myconfig, $mref->{validto});
  818. }
  819. # convert price
  820. $sellprice = $form->round_amount($mref->{sellprice} * $form->{$mref->{curr}}, $decimalplaces);
  821. if ($mref->{customer_id}) {
  822. $ref->{sellprice} = $sellprice if !$mref->{pricebreak};
  823. $p{$mref->{pricebreak}} = $sellprice;
  824. $customerprice = 1;
  825. }
  826. if ($mref->{pricegroup_id}) {
  827. if (! $customerprice) {
  828. $ref->{sellprice} = $sellprice if !$mref->{pricebreak};
  829. $p{$mref->{pricebreak}} = $sellprice;
  830. }
  831. $pricegroupprice = 1;
  832. }
  833. if (!$customerprice && !$pricegroupprice) {
  834. $p{$mref->{pricebreak}} = $sellprice;
  835. }
  836. }
  837. $pmh->finish;
  838. if (%p) {
  839. if ($ref->{sellprice}) {
  840. $p{0} = $ref->{sellprice};
  841. }
  842. for (sort { $a <=> $b } keys %p) { $ref->{pricematrix} .= "${_}:$p{$_} " }
  843. } else {
  844. if ($init) {
  845. $ref->{sellprice} = $form->round_amount($ref->{sellprice}, $decimalplaces);
  846. } else {
  847. $ref->{sellprice} = $form->round_amount($ref->{sellprice} * (1 - $form->{tradediscount}), $decimalplaces);
  848. }
  849. $ref->{pricematrix} = "0:$ref->{sellprice} " if $ref->{sellprice};
  850. }
  851. chop $ref->{pricematrix};
  852. }
  853. if ($form->{vendor_id}) {
  854. $pmh->execute($ref->{id});
  855. $mref = $pmh->fetchrow_hashref(NAME_lc);
  856. if ($mref->{partnumber} ne "") {
  857. $ref->{partnumber} = $mref->{partnumber};
  858. }
  859. if ($mref->{lastcost}) {
  860. # do a conversion
  861. $ref->{sellprice} = $form->round_amount($mref->{lastcost} * $form->{$mref->{curr}}, $decimalplaces);
  862. }
  863. $pmh->finish;
  864. $ref->{sellprice} *= 1;
  865. # add 0:price to matrix
  866. $ref->{pricematrix} = "0:$ref->{sellprice}";
  867. }
  868. }
  869. sub exchangerate_defaults {
  870. my ($dbh, $form) = @_;
  871. my $var;
  872. my $buysell = ($form->{vc} eq "customer") ? "buy" : "sell";
  873. # get default currencies
  874. my $query = qq|SELECT substr(curr,1,3), curr FROM defaults|;
  875. ($form->{defaultcurrency}, $form->{currencies}) = $dbh->selectrow_array($query);
  876. $query = qq|SELECT $buysell
  877. FROM exchangerate
  878. WHERE curr = ?
  879. AND transdate = ?|;
  880. my $eth1 = $dbh->prepare($query) || $form->dberror($query);
  881. $query = qq~SELECT max(transdate || ' ' || $buysell || ' ' || curr)
  882. FROM exchangerate
  883. WHERE curr = ?~;
  884. my $eth2 = $dbh->prepare($query) || $form->dberror($query);
  885. # get exchange rates for transdate or max
  886. foreach $var (split /:/, substr($form->{currencies},4)) {
  887. $eth1->execute($var, $form->{transdate});
  888. ($form->{$var}) = $eth1->fetchrow_array;
  889. if (! $form->{$var} ) {
  890. $eth2->execute($var);
  891. ($form->{$var}) = $eth2->fetchrow_array;
  892. ($null, $form->{$var}) = split / /, $form->{$var};
  893. $form->{$var} = 1 unless $form->{$var};
  894. $eth2->finish;
  895. }
  896. $eth1->finish;
  897. }
  898. $form->{$form->{currency}} = $form->{exchangerate} if $form->{exchangerate};
  899. $form->{$form->{currency}} ||= 1;
  900. $form->{$form->{defaultcurrency}} = 1;
  901. }
  902. sub order_details {
  903. my ($self, $myconfig, $form) = @_;
  904. # connect to database
  905. my $dbh = $form->dbconnect($myconfig);
  906. my $query;
  907. my $sth;
  908. my $item;
  909. my $i;
  910. my @sortlist = ();
  911. my $projectnumber;
  912. my $projectdescription;
  913. my $projectnumber_id;
  914. my $translation;
  915. my $partsgroup;
  916. my %oid = ( 'Pg' => 'TRUE',
  917. 'PgPP' => 'TRUE',
  918. 'Oracle' => 'rowid',
  919. 'DB2' => '1=1'
  920. );
  921. my @taxaccounts;
  922. my %taxaccounts;
  923. my $tax;
  924. my $taxrate;
  925. my $taxamount;
  926. my %translations;
  927. $query = qq|SELECT p.description, t.description
  928. FROM project p
  929. LEFT JOIN translation t ON (t.trans_id = p.id AND t.language_code = '$form->{language_code}')
  930. WHERE id = ?|;
  931. my $prh = $dbh->prepare($query) || $form->dberror($query);
  932. $query = qq|SELECT inventory_accno_id, income_accno_id,
  933. expense_accno_id, assembly FROM parts
  934. WHERE id = ?|;
  935. my $pth = $dbh->prepare($query) || $form->dberror($query);
  936. my $sortby;
  937. # sort items by project and partsgroup
  938. for $i (1 .. $form->{rowcount}) {
  939. if ($form->{"id_$i"}) {
  940. # account numbers
  941. $pth->execute($form->{"id_$i"});
  942. $ref = $pth->fetchrow_hashref(NAME_lc);
  943. for (keys %$ref) { $form->{"${_}_$i"} = $ref->{$_} }
  944. $pth->finish;
  945. $projectnumber_id = 0;
  946. $projectnumber = "";
  947. $form->{partsgroup} = "";
  948. $form->{projectnumber} = "";
  949. if ($form->{groupprojectnumber} || $form->{grouppartsgroup}) {
  950. $inventory_accno_id = ($form->{"inventory_accno_id_$i"} || $form->{"assembly_$i"}) ? "1" : "";
  951. if ($form->{groupprojectnumber}) {
  952. ($projectnumber, $projectnumber_id) = split /--/, $form->{"projectnumber_$i"};
  953. }
  954. if ($form->{grouppartsgroup}) {
  955. ($form->{partsgroup}) = split /--/, $form->{"partsgroup_$i"};
  956. }
  957. if ($projectnumber_id && $form->{groupprojectnumber}) {
  958. if ($translation{$projectnumber_id}) {
  959. $form->{projectnumber} = $translation{$projectnumber_id};
  960. } else {
  961. # get project description
  962. $prh->execute($projectnumber_id);
  963. ($projectdescription, $translation) = $prh->fetchrow_array;
  964. $prh->finish;
  965. $form->{projectnumber} = ($translation) ? "$projectnumber, $translation" : "$projectnumber, $projectdescription";
  966. $translation{$projectnumber_id} = $form->{projectnumber};
  967. }
  968. }
  969. if ($form->{grouppartsgroup} && $form->{partsgroup}) {
  970. $form->{projectnumber} .= " / " if $projectnumber_id;
  971. $form->{projectnumber} .= $form->{partsgroup};
  972. }
  973. $form->format_string(projectnumber);
  974. }
  975. $sortby = qq|$projectnumber$form->{partsgroup}|;
  976. if ($form->{sortby} ne 'runningnumber') {
  977. for (qw(partnumber description bin)) {
  978. $sortby .= $form->{"${_}_$i"} if $form->{sortby} eq $_;
  979. }
  980. }
  981. push @sortlist, [ $i, qq|$projectnumber$form->{partsgroup}$inventory_accno_id|, $form->{projectnumber}, $projectnumber_id, $form->{partsgroup}, $sortby ];
  982. }
  983. }
  984. delete $form->{projectnumber};
  985. # sort the whole thing by project and group
  986. @sortlist = sort { $a->[5] cmp $b->[5] } @sortlist;
  987. # if there is a warehouse limit picking
  988. if ($form->{warehouse_id} && $form->{formname} =~ /(pick|packing)_list/) {
  989. # run query to check for inventory
  990. $query = qq|SELECT sum(qty) AS qty
  991. FROM inventory
  992. WHERE parts_id = ?
  993. AND warehouse_id = ?|;
  994. $sth = $dbh->prepare($query) || $form->dberror($query);
  995. for $i (1 .. $form->{rowcount}) {
  996. $sth->execute($form->{"id_$i"}, $form->{warehouse_id}) || $form->dberror;
  997. ($qty) = $sth->fetchrow_array;
  998. $sth->finish;
  999. $form->{"qty_$i"} = 0 if $qty == 0;
  1000. if ($form->parse_amount($myconfig, $form->{"ship_$i"}) > $qty) {
  1001. $form->{"ship_$i"} = $form->format_amount($myconfig, $qty);
  1002. }
  1003. }
  1004. }
  1005. my $runningnumber = 1;
  1006. my $sameitem = "";
  1007. my $subtotal;
  1008. my $k = scalar @sortlist;
  1009. my $j = 0;
  1010. foreach $item (@sortlist) {
  1011. $i = $item->[0];
  1012. $j++;
  1013. if ($form->{groupprojectnumber} || $form->{grouppartsgroup}) {
  1014. if ($item->[1] ne $sameitem) {
  1015. $sameitem = $item->[1];
  1016. $ok = 0;
  1017. if ($form->{groupprojectnumber}) {
  1018. $ok = $form->{"projectnumber_$i"};
  1019. }
  1020. if ($form->{grouppartsgroup}) {
  1021. $ok = $form->{"partsgroup_$i"} unless $ok;
  1022. }
  1023. if ($ok) {
  1024. if ($form->{"inventory_accno_id_$i"} || $form->{"assembly_$i"}) {
  1025. push(@{ $form->{part} }, "");
  1026. push(@{ $form->{service} }, NULL);
  1027. } else {
  1028. push(@{ $form->{part} }, NULL);
  1029. push(@{ $form->{service} }, "");
  1030. }
  1031. push(@{ $form->{description} }, $item->[2]);
  1032. for (qw(taxrates runningnumber number sku qty ship unit bin serialnumber requiredate projectnumber sellprice listprice netprice discount discountrate linetotal weight itemnotes)) { push(@{ $form->{$_} }, "") }
  1033. push(@{ $form->{lineitems} }, { amount => 0, tax => 0 });
  1034. }
  1035. }
  1036. }
  1037. $form->{"qty_$i"} = $form->parse_amount($myconfig, $form->{"qty_$i"});
  1038. $form->{"ship_$i"} = $form->parse_amount($myconfig, $form->{"ship_$i"});
  1039. if ($form->{"qty_$i"}) {
  1040. $form->{totalqty} += $form->{"qty_$i"};
  1041. $form->{totalship} += $form->{"ship_$i"};
  1042. $form->{totalweight} += ($form->{"weight_$i"} * $form->{"qty_$i"});
  1043. $form->{totalweightship} += ($form->{"weight_$i"} * $form->{"ship_$i"});
  1044. # add number, description and qty to $form->{number}, ....
  1045. push(@{ $form->{runningnumber} }, $runningnumber++);
  1046. push(@{ $form->{number} }, qq|$form->{"partnumber_$i"}|);
  1047. push(@{ $form->{sku} }, qq|$form->{"sku_$i"}|);
  1048. push(@{ $form->{description} }, qq|$form->{"description_$i"}|);
  1049. push(@{ $form->{itemnotes} }, $form->{"notes_$i"});
  1050. push(@{ $form->{qty} }, $form->format_amount($myconfig, $form->{"qty_$i"}));
  1051. push(@{ $form->{ship} }, $form->format_amount($myconfig, $form->{"ship_$i"}));
  1052. push(@{ $form->{unit} }, qq|$form->{"unit_$i"}|);
  1053. push(@{ $form->{bin} }, qq|$form->{"bin_$i"}|);
  1054. push(@{ $form->{serialnumber} }, qq|$form->{"serialnumber_$i"}|);
  1055. push(@{ $form->{requiredate} }, qq|$form->{"reqdate_$i"}|);
  1056. push(@{ $form->{projectnumber} }, qq|$form->{"projectnumber_$i"}|);
  1057. push(@{ $form->{sellprice} }, $form->{"sellprice_$i"});
  1058. push(@{ $form->{listprice} }, $form->{"listprice_$i"});
  1059. push(@{ $form->{weight} }, $form->format_amount($myconfig, $form->{"weight_$i"} * $form->{"ship_$i"}));
  1060. my $sellprice = $form->parse_amount($myconfig, $form->{"sellprice_$i"});
  1061. my ($dec) = ($sellprice =~ /\.(\d+)/);
  1062. $dec = length $dec;
  1063. my $decimalplaces = ($dec > 2) ? $dec : 2;
  1064. my $discount = $form->round_amount($sellprice * $form->parse_amount($myconfig, $form->{"discount_$i"}) / 100, $decimalplaces);
  1065. # keep a netprice as well, (sellprice - discount)
  1066. $form->{"netprice_$i"} = $sellprice - $discount;
  1067. my $linetotal = $form->round_amount($form->{"qty_$i"} * $form->{"netprice_$i"}, 2);
  1068. if ($form->{"inventory_accno_id_$i"} || $form->{"assembly_$i"}) {
  1069. push(@{ $form->{part} }, $form->{"sku_$i"});
  1070. push(@{ $form->{service} }, NULL);
  1071. $form->{totalparts} += $linetotal;
  1072. } else {
  1073. push(@{ $form->{service} }, $form->{"sku_$i"});
  1074. push(@{ $form->{part} }, NULL);
  1075. $form->{totalservices} += $linetotal;
  1076. }
  1077. push(@{ $form->{netprice} }, ($form->{"netprice_$i"}) ? $form->format_amount($myconfig, $form->{"netprice_$i"}, $decimalplaces) : " ");
  1078. $discount = ($discount) ? $form->format_amount($myconfig, $discount * -1, $decimalplaces) : " ";
  1079. push(@{ $form->{discount} }, $discount);
  1080. push(@{ $form->{discountrate} }, $form->format_amount($myconfig, $form->{"discount_$i"}));
  1081. $form->{ordtotal} += $linetotal;
  1082. # this is for the subtotals for grouping
  1083. $subtotal += $linetotal;
  1084. $form->{"linetotal_$i"} = $form->format_amount($myconfig, $linetotal, 2);
  1085. push(@{ $form->{linetotal} }, $form->{"linetotal_$i"});
  1086. @taxaccounts = split / /, $form->{"taxaccounts_$i"};
  1087. my $ml = 1;
  1088. my @taxrates = ();
  1089. $tax = 0;
  1090. for (0 .. 1) {
  1091. $taxrate = 0;
  1092. for (@taxaccounts) { $taxrate += $form->{"${_}_rate"} if ($form->{"${_}_rate"} * $ml) > 0 }
  1093. $taxrate *= $ml;
  1094. $taxamount = $linetotal * $taxrate / (1 + $taxrate);
  1095. $taxbase = ($linetotal - $taxamount);
  1096. foreach $item (@taxaccounts) {
  1097. if (($form->{"${item}_rate"} * $ml) > 0) {
  1098. push @taxrates, $form->{"${item}_rate"} * 100;
  1099. if ($form->{taxincluded}) {
  1100. $taxaccounts{$item} += $linetotal * $form->{"${item}_rate"} / (1 + $taxrate);
  1101. $taxbase{$item} += $taxbase;
  1102. } else {
  1103. $taxbase{$item} += $linetotal;
  1104. $taxaccounts{$item} += $linetotal * $form->{"${item}_rate"};
  1105. }
  1106. }
  1107. }
  1108. if ($form->{taxincluded}) {
  1109. $tax += $linetotal * ($taxrate / (1 + ($taxrate * $ml)));
  1110. } else {
  1111. $tax += $linetotal * $taxrate;
  1112. }
  1113. $ml *= -1;
  1114. }
  1115. push(@{ $form->{lineitems} }, { amount => $linetotal, tax => $form->round_amount($tax, 2) });
  1116. push(@{ $form->{taxrates} }, join ' ', sort { $a <=> $b } @taxrates);
  1117. if ($form->{"assembly_$i"}) {
  1118. $form->{stagger} = -1;
  1119. &assembly_details($myconfig, $form, $dbh, $form->{"id_$i"}, $oid{$myconfig->{dbdriver}}, $form->{"qty_$i"});
  1120. }
  1121. }
  1122. # add subtotal
  1123. if ($form->{groupprojectnumber} || $form->{grouppartsgroup}) {
  1124. if ($subtotal) {
  1125. if ($j < $k) {
  1126. # look at next item
  1127. if ($sortlist[$j]->[1] ne $sameitem) {
  1128. if ($form->{"inventory_accno_id_$i"} || $form->{"assembly_$i"}) {
  1129. push(@{ $form->{part} }, "");
  1130. push(@{ $form->{service} }, NULL);
  1131. } else {
  1132. push(@{ $form->{service} }, "");
  1133. push(@{ $form->{part} }, NULL);
  1134. }
  1135. for (qw(taxrates runningnumber number sku qty ship unit bin serialnumber requiredate projectnumber sellprice listprice netprice discount discountrate weight itemnotes)) { push(@{ $form->{$_} }, "") }
  1136. push(@{ $form->{description} }, $form->{groupsubtotaldescription});
  1137. push(@{ $form->{lineitems} }, { amount => 0, tax => 0 });
  1138. if ($form->{groupsubtotaldescription} ne "") {
  1139. push(@{ $form->{linetotal} }, $form->format_amount($myconfig, $subtotal, 2));
  1140. } else {
  1141. push(@{ $form->{linetotal} }, "");
  1142. }
  1143. $subtotal = 0;
  1144. }
  1145. } else {
  1146. # got last item
  1147. if ($form->{groupsubtotaldescription} ne "") {
  1148. if ($form->{"inventory_accno_id_$i"} || $form->{"assembly_$i"}) {
  1149. push(@{ $form->{part} }, "");
  1150. push(@{ $form->{service} }, NULL);
  1151. } else {
  1152. push(@{ $form->{service} }, "");
  1153. push(@{ $form->{part} }, NULL);
  1154. }
  1155. for (qw(taxrates runningnumber number sku qty ship unit bin serialnumber requiredate projectnumber sellprice listprice netprice discount discountrate weight itemnotes)) { push(@{ $form->{$_} }, "") }
  1156. push(@{ $form->{description} }, $form->{groupsubtotaldescription});
  1157. push(@{ $form->{linetotal} }, $form->format_amount($myconfig, $subtotal, 2));
  1158. push(@{ $form->{lineitems} }, { amount => 0, tax => 0 });
  1159. }
  1160. }
  1161. }
  1162. }
  1163. }
  1164. $tax = 0;
  1165. foreach $item (sort keys %taxaccounts) {
  1166. if ($form->round_amount($taxaccounts{$item}, 2)) {
  1167. $tax += $taxamount = $form->round_amount($taxaccounts{$item}, 2);
  1168. push(@{ $form->{taxbaseinclusive} }, $form->{"${item}_taxbaseinclusive"} = $form->round_amount($taxbase{$item} + $tax, 2));
  1169. push(@{ $form->{taxbase} }, $form->{"${item}_taxbase"} = $form->format_amount($myconfig, $taxbase{$item}, 2));
  1170. push(@{ $form->{tax} }, $form->{"${item}_tax"} = $form->format_amount($myconfig, $taxamount, 2));
  1171. push(@{ $form->{taxdescription} }, $form->{"${item}_description"});
  1172. $form->{"${item}_taxrate"} = $form->format_amount($myconfig, $form->{"${item}_rate"} * 100);
  1173. push(@{ $form->{taxrate} }, $form->{"${item}_taxrate"});
  1174. push(@{ $form->{taxnumber} }, $form->{"${item}_taxnumber"});
  1175. }
  1176. }
  1177. # adjust taxes for lineitems
  1178. my $total = 0;
  1179. for (@{ $form->{lineitems} }) {
  1180. $total += $_->{tax};
  1181. }
  1182. if ($form->round_amount($total,2) != $form->round_amount($tax,2)) {
  1183. # get largest amount
  1184. for (reverse sort { $a->{tax} <=> $b->{tax} } @{ $form->{lineitems} }) {
  1185. $_->{tax} -= $total - $tax;
  1186. last;
  1187. }
  1188. }
  1189. $i = 1;
  1190. for (@{ $form->{lineitems} }) {
  1191. push(@{ $form->{linetax} }, $form->format_amount($myconfig, $_->{tax}, 2, ""));
  1192. }
  1193. for (qw(totalparts totalservices)) { $form->{$_} = $form->format_amount($myconfig, $form->{$_}, 2) }
  1194. for (qw(totalqty totalship totalweight)) { $form->{$_} = $form->format_amount($myconfig, $form->{$_}) }
  1195. $form->{subtotal} = $form->format_amount($myconfig, $form->{ordtotal}, 2);
  1196. $form->{ordtotal} = ($form->{taxincluded}) ? $form->{ordtotal} : $form->{ordtotal} + $tax;
  1197. use LedgerSMB::CP;
  1198. my $c;
  1199. if ($form->{language_code} ne "") {
  1200. $c = new CP $form->{language_code};
  1201. } else {
  1202. $c = new CP $myconfig->{countrycode};
  1203. }
  1204. $c->init;
  1205. my $whole;
  1206. ($whole, $form->{decimal}) = split /\./, $form->{ordtotal};
  1207. $form->{decimal} .= "00";
  1208. $form->{decimal} = substr($form->{decimal}, 0, 2);
  1209. $form->{text_decimal} = $c->num2text($form->{decimal} * 1);
  1210. $form->{text_amount} = $c->num2text($whole);
  1211. $form->{integer_amount} = $form->format_amount($myconfig, $whole);
  1212. # format amounts
  1213. $form->{quototal} = $form->{ordtotal} = $form->format_amount($myconfig, $form->{ordtotal}, 2);
  1214. $form->format_string(qw(text_amount text_decimal));
  1215. $query = qq|SELECT weightunit FROM defaults|;
  1216. ($form->{weightunit}) = $dbh->selectrow_array($query);
  1217. $dbh->disconnect;
  1218. }
  1219. sub assembly_details {
  1220. my ($myconfig, $form, $dbh, $id, $oid, $qty) = @_;
  1221. my $sm = "";
  1222. my $spacer;
  1223. $form->{stagger}++;
  1224. if ($form->{format} eq 'html') {
  1225. $spacer = "&nbsp;" x (3 * ($form->{stagger} - 1)) if $form->{stagger} > 1;
  1226. }
  1227. if ($form->{format} =~ /(postscript|pdf)/) {
  1228. if ($form->{stagger} > 1) {
  1229. $spacer = ($form->{stagger} - 1) * 3;
  1230. $spacer = '\rule{'.$spacer.'mm}{0mm}';
  1231. }
  1232. }
  1233. # get parts and push them onto the stack
  1234. my $sortorder = "";
  1235. if ($form->{grouppartsgroup}) {
  1236. $sortorder = qq|ORDER BY pg.partsgroup, a.$oid|;
  1237. } else {
  1238. $sortorder = qq|ORDER BY a.$oid|;
  1239. }
  1240. my $where = ($form->{formname} eq 'work_order') ? "1 = 1" : "a.bom = '1'";
  1241. my $query = qq|SELECT p.partnumber, p.description, p.unit, a.qty,
  1242. pg.partsgroup, p.partnumber AS sku, p.assembly, p.id, p.bin
  1243. FROM assembly a
  1244. JOIN parts p ON (a.parts_id = p.id)
  1245. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  1246. WHERE $where
  1247. AND a.id = '$id'
  1248. $sortorder|;
  1249. my $sth = $dbh->prepare($query);
  1250. $sth->execute || $form->dberror($query);
  1251. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  1252. for (qw(partnumber description partsgroup)) {
  1253. $form->{"a_$_"} = $ref->{$_};
  1254. $form->format_string("a_$_");
  1255. }
  1256. if ($form->{grouppartsgroup} && $ref->{partsgroup} ne $sm) {
  1257. for (qw(taxrates number sku unit qty runningnumber ship bin serialnumber requiredate projectnumber sellprice listprice netprice discount discountrate linetotal weight itemnotes)) { push(@{ $form->{$_} }, "") }
  1258. $sm = ($form->{"a_partsgroup"}) ? $form->{"a_partsgroup"} : "";
  1259. push(@{ $form->{description} }, "$spacer$sm");
  1260. push(@{ $form->{lineitems} }, { amount => 0, tax => 0 });
  1261. }
  1262. if ($form->{stagger}) {
  1263. push(@{ $form->{description} }, qq|$spacer$form->{"a_partnumber"}, $form->{"a_description"}|);
  1264. for (qw(taxrates number sku runningnumber ship serialnumber requiredate projectnumber sellprice listprice netprice discount discountrate linetotal weight itemnotes)) { push(@{ $form->{$_} }, "") }
  1265. } else {
  1266. push(@{ $form->{description} }, qq|$form->{"a_description"}|);
  1267. push(@{ $form->{sku} }, $form->{"a_partnumber"});
  1268. push(@{ $form->{number} }, $form->{"a_partnumber"});
  1269. for (qw(taxrates runningnumber ship serialnumber requiredate projectnumber sellprice listprice netprice discount discountrate linetotal weight itemnotes)) { push(@{ $form->{$_} }, "") }
  1270. }
  1271. push(@{ $form->{lineitems} }, { amount => 0, tax => 0 });
  1272. push(@{ $form->{qty} }, $form->format_amount($myconfig, $ref->{qty} * $qty));
  1273. for (qw(unit bin)) {
  1274. $form->{"a_$_"} = $ref->{$_};
  1275. $form->format_string("a_$_");
  1276. push(@{ $form->{$_} }, $form->{"a_$_"});
  1277. }
  1278. if ($ref->{assembly} && $form->{formname} eq 'work_order') {
  1279. &assembly_details($myconfig, $form, $dbh, $ref->{id}, $oid, $ref->{qty} * $qty);
  1280. }
  1281. }
  1282. $sth->finish;
  1283. $form->{stagger}--;
  1284. }
  1285. sub project_description {
  1286. my ($self, $dbh, $id) = @_;
  1287. my $query = qq|SELECT description
  1288. FROM project
  1289. WHERE id = $id|;
  1290. ($_) = $dbh->selectrow_array($query);
  1291. $_;
  1292. }
  1293. sub get_warehouses {
  1294. my ($self, $myconfig, $form) = @_;
  1295. my $dbh = $form->dbconnect($myconfig);
  1296. # setup warehouses
  1297. my $query = qq|SELECT id, description
  1298. FROM warehouse
  1299. ORDER BY 2|;
  1300. my $sth = $dbh->prepare($query);
  1301. $sth->execute || $form->dberror($query);
  1302. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  1303. push @{ $form->{all_warehouse} }, $ref;
  1304. }
  1305. $sth->finish;
  1306. $dbh->disconnect;
  1307. }
  1308. sub save_inventory {
  1309. my ($self, $myconfig, $form) = @_;
  1310. my ($null, $warehouse_id) = split /--/, $form->{warehouse};
  1311. $warehouse_id *= 1;
  1312. my $ml = ($form->{type} eq 'ship_order') ? -1 : 1;
  1313. my $dbh = $form->dbconnect_noauto($myconfig);
  1314. my $sth;
  1315. my $wth;
  1316. my $serialnumber;
  1317. my $ship;
  1318. my ($null, $employee_id) = split /--/, $form->{employee};
  1319. ($null, $employee_id) = $form->get_employee($dbh) if ! $employee_id;
  1320. $query = qq|SELECT serialnumber, ship
  1321. FROM orderitems
  1322. WHERE trans_id = ?
  1323. AND id = ?
  1324. FOR UPDATE|;
  1325. $sth = $dbh->prepare($query) || $form->dberror($query);
  1326. $query = qq|SELECT sum(qty)
  1327. FROM inventory
  1328. WHERE parts_id = ?
  1329. AND warehouse_id = ?|;
  1330. $wth = $dbh->prepare($query) || $form->dberror($query);
  1331. for my $i (1 .. $form->{rowcount}) {
  1332. $ship = (abs($form->{"ship_$i"}) > abs($form->{"qty_$i"})) ? $form->{"qty_$i"} : $form->{"ship_$i"};
  1333. if ($warehouse_id && $form->{type} eq 'ship_order') {
  1334. $wth->execute($form->{"id_$i"}, $warehouse_id) || $form->dberror;
  1335. ($qty) = $wth->fetchrow_array;
  1336. $wth->finish;
  1337. if ($ship > $qty) {
  1338. $ship = $qty;
  1339. }
  1340. }
  1341. if ($ship) {
  1342. $ship *= $ml;
  1343. $query = qq|INSERT INTO inventory (parts_id, warehouse_id,
  1344. qty, trans_id, orderitems_id, shippingdate, employee_id)
  1345. VALUES ($form->{"id_$i"}, $warehouse_id,
  1346. $ship, $form->{"id"},
  1347. $form->{"orderitems_id_$i"}, '$form->{shippingdate}',
  1348. $employee_id)|;
  1349. $dbh->do($query) || $form->dberror($query);
  1350. # add serialnumber, ship to orderitems
  1351. $sth->execute($form->{id}, $form->{"orderitems_id_$i"}) || $form->dberror;
  1352. ($serialnumber, $ship) = $sth->fetchrow_array;
  1353. $sth->finish;
  1354. $serialnumber .= " " if $serialnumber;
  1355. $serialnumber .= qq|$form->{"serialnumber_$i"}|;
  1356. $ship += $form->{"ship_$i"};
  1357. $query = qq|UPDATE orderitems SET
  1358. serialnumber = '$serialnumber',
  1359. ship = $ship,
  1360. reqdate = '$form->{shippingdate}'
  1361. WHERE trans_id = $form->{id}
  1362. AND id = $form->{"orderitems_id_$i"}|;
  1363. $dbh->do($query) || $form->dberror($query);
  1364. # update order with ship via
  1365. $query = qq|UPDATE oe SET
  1366. shippingpoint = |.$dbh->quote($form->{shippingpoint}).qq|,
  1367. shipvia = |.$dbh->quote($form->{shipvia}).qq|
  1368. WHERE id = $form->{id}|;
  1369. $dbh->do($query) || $form->dberror($query);
  1370. # update onhand for parts
  1371. $form->update_balance($dbh,
  1372. "parts",
  1373. "onhand",
  1374. qq|id = $form->{"id_$i"}|,
  1375. $form->{"ship_$i"} * $ml);
  1376. }
  1377. }
  1378. my $rc = $dbh->commit;
  1379. $dbh->disconnect;
  1380. $rc;
  1381. }
  1382. sub adj_onhand {
  1383. my ($dbh, $form, $ml) = @_;
  1384. my $query = qq|SELECT oi.parts_id, oi.ship, p.inventory_accno_id, p.assembly
  1385. FROM orderitems oi
  1386. JOIN parts p ON (p.id = oi.parts_id)
  1387. WHERE oi.trans_id = $form->{id}|;
  1388. my $sth = $dbh->prepare($query);
  1389. $sth->execute || $form->dberror($query);
  1390. $query = qq|SELECT sum(p.inventory_accno_id), p.assembly
  1391. FROM parts p
  1392. JOIN assembly a ON (a.parts_id = p.id)
  1393. WHERE a.id = ?
  1394. GROUP BY p.assembly|;
  1395. my $ath = $dbh->prepare($query) || $form->dberror($query);
  1396. my $ref;
  1397. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1398. if ($ref->{inventory_accno_id} || $ref->{assembly}) {
  1399. # do not update if assembly consists of all services
  1400. if ($ref->{assembly}) {
  1401. $ath->execute($ref->{parts_id}) || $form->dberror($query);
  1402. my ($inv, $assembly) = $ath->fetchrow_array;
  1403. $ath->finish;
  1404. next unless ($inv || $assembly);
  1405. }
  1406. # adjust onhand in parts table
  1407. $form->update_balance($dbh,
  1408. "parts",
  1409. "onhand",
  1410. qq|id = $ref->{parts_id}|,
  1411. $ref->{ship} * $ml);
  1412. }
  1413. }
  1414. $sth->finish;
  1415. }
  1416. sub adj_inventory {
  1417. my ($dbh, $myconfig, $form) = @_;
  1418. my %oid = ( 'Pg' => 'id',
  1419. 'PgPP' => 'id',
  1420. 'Oracle' => 'rowid',
  1421. 'DB2' => '1=1'
  1422. );
  1423. # increase/reduce qty in inventory table
  1424. my $query = qq|SELECT oi.id, oi.parts_id, oi.ship
  1425. FROM orderitems oi
  1426. WHERE oi.trans_id = $form->{id}|;
  1427. my $sth = $dbh->prepare($query);
  1428. $sth->execute || $form->dberror($query);
  1429. $query = qq|SELECT qty,
  1430. (SELECT SUM(qty) FROM inventory
  1431. WHERE trans_id = $form->{id}
  1432. AND orderitems_id = ?) AS total
  1433. FROM inventory
  1434. WHERE trans_id = $form->{id}
  1435. AND orderitems_id = ?|;
  1436. my $ith = $dbh->prepare($query) || $form->dberror($query);
  1437. my $qty;
  1438. my $ml = ($form->{type} =~ /(ship|sales)_order/) ? -1 : 1;
  1439. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  1440. $ith->execute($ref->{id}, $ref->{id}) || $form->dberror($query);
  1441. my $ship = $ref->{ship};
  1442. while (my $inv = $ith->fetchrow_hashref(NAME_lc)) {
  1443. if (($qty = (($inv->{total} * $ml) - $ship)) >= 0) {
  1444. $qty = $inv->{qty} * $ml if ($qty > ($inv->{qty} * $ml));
  1445. $form->update_balance($dbh,
  1446. "inventory",
  1447. "qty",
  1448. qq|$oid{$myconfig->{dbdriver}} = $inv->{oid}|,
  1449. $qty * -1 * $ml);
  1450. $ship -= $qty;
  1451. }
  1452. }
  1453. $ith->finish;
  1454. }
  1455. $sth->finish;
  1456. # delete inventory entries if qty = 0
  1457. $query = qq|DELETE FROM inventory
  1458. WHERE trans_id = $form->{id}
  1459. AND qty = 0|;
  1460. $dbh->do($query) || $form->dberror($query);
  1461. }
  1462. sub get_inventory {
  1463. my ($self, $myconfig, $form) = @_;
  1464. my $where;
  1465. my $query;
  1466. my $null;
  1467. my $fromwarehouse_id;
  1468. my $towarehouse_id;
  1469. my $var;
  1470. my $dbh = $form->dbconnect($myconfig);
  1471. if ($form->{partnumber} ne "") {
  1472. $var = $form->like(lc $form->{partnumber});
  1473. $where .= "
  1474. AND lower(p.partnumber) LIKE '$var'";
  1475. }
  1476. if ($form->{description} ne "") {
  1477. $var = $form->like(lc $form->{description});
  1478. $where .= "
  1479. AND lower(p.description) LIKE '$var'";
  1480. }
  1481. if ($form->{partsgroup} ne "") {
  1482. ($null, $var) = split /--/, $form->{partsgroup};
  1483. $where .= "
  1484. AND pg.id = $var";
  1485. }
  1486. ($null, $fromwarehouse_id) = split /--/, $form->{fromwarehouse};
  1487. $fromwarehouse_id *= 1;
  1488. ($null, $towarehouse_id) = split /--/, $form->{towarehouse};
  1489. $towarehouse_id *= 1;
  1490. my %ordinal = ( partnumber => 2,
  1491. description => 3,
  1492. partsgroup => 5,
  1493. warehouse => 6,
  1494. );
  1495. my @a = (partnumber, warehouse);
  1496. my $sortorder = $form->sort_order(\@a, \%ordinal);
  1497. if ($fromwarehouse_id) {
  1498. if ($towarehouse_id) {
  1499. $where .= "
  1500. AND NOT i.warehouse_id = $towarehouse_id";
  1501. }
  1502. $query = qq|SELECT p.id, p.partnumber, p.description,
  1503. sum(i.qty) * 2 AS onhand, sum(i.qty) AS qty,
  1504. pg.partsgroup, w.description AS warehouse, i.warehouse_id
  1505. FROM inventory i
  1506. JOIN parts p ON (p.id = i.parts_id)
  1507. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  1508. JOIN warehouse w ON (w.id = i.warehouse_id)
  1509. WHERE i.warehouse_id = $fromwarehouse_id
  1510. $where
  1511. GROUP BY p.id, p.partnumber, p.description, pg.partsgroup, w.description, i.warehouse_id
  1512. ORDER BY $sortorder|;
  1513. } else {
  1514. if ($towarehouse_id) {
  1515. $query = qq|
  1516. SELECT p.id, p.partnumber, p.description,
  1517. p.onhand, (SELECT SUM(qty) FROM inventory i WHERE i.parts_id = p.id) AS qty,
  1518. pg.partsgroup, '' AS warehouse, 0 AS warehouse_id
  1519. FROM parts p
  1520. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  1521. WHERE p.onhand > 0
  1522. $where
  1523. UNION|;
  1524. }
  1525. $query .= qq|
  1526. SELECT p.id, p.partnumber, p.description,
  1527. sum(i.qty) * 2 AS onhand, sum(i.qty) AS qty,
  1528. pg.partsgroup, w.description AS warehouse, i.warehouse_id
  1529. FROM inventory i
  1530. JOIN parts p ON (p.id = i.parts_id)
  1531. LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id)
  1532. JOIN warehouse w ON (w.id = i.warehouse_id)
  1533. WHERE i.warehouse_id != $towarehouse_id
  1534. $where
  1535. GROUP BY p.id, p.partnumber, p.description, pg.partsgroup, w.description, i.warehouse_id
  1536. ORDER BY $sortorder|;
  1537. }
  1538. my $sth = $dbh->prepare($query);
  1539. $sth->execute || $form->dberror($query);
  1540. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1541. $ref->{qty} = $ref->{onhand} - $ref->{qty};
  1542. push @{ $form->{all_inventory} }, $ref if $ref->{qty} > 0;
  1543. }
  1544. $sth->finish;
  1545. $dbh->disconnect;
  1546. }
  1547. sub transfer {
  1548. my ($self, $myconfig, $form) = @_;
  1549. my $dbh = $form->dbconnect_noauto($myconfig);
  1550. ($form->{employee}, $form->{employee_id}) = $form->get_employee($dbh);
  1551. my @a = localtime;
  1552. $a[5] += 1900;
  1553. $a[4]++;
  1554. $a[4] = substr("0$a[4]", -2);
  1555. $a[3] = substr("0$a[3]", -2);
  1556. $shippingdate = "$a[5]$a[4]$a[3]";
  1557. my %total = ();
  1558. my $query = qq|INSERT INTO inventory
  1559. (warehouse_id, parts_id, qty, shippingdate, employee_id)
  1560. VALUES (?, ?, ?, '$shippingdate', $form->{employee_id})|;
  1561. $sth = $dbh->prepare($query) || $form->dberror($query);
  1562. my $qty;
  1563. for my $i (1 .. $form->{rowcount}) {
  1564. $qty = $form->parse_amount($myconfig, $form->{"transfer_$i"});
  1565. $qty = $form->{"qty_$i"} if ($qty > $form->{"qty_$i"});
  1566. if ($qty > 0) {
  1567. # to warehouse
  1568. if ($form->{warehouse_id}) {
  1569. $sth->execute($form->{warehouse_id}, $form->{"id_$i"}, $qty) || $form->dberror;
  1570. $sth->finish;
  1571. }
  1572. # from warehouse
  1573. if ($form->{"warehouse_id_$i"}) {
  1574. $sth->execute($form->{"warehouse_id_$i"}, $form->{"id_$i"}, $qty * -1) || $form->dberror;
  1575. $sth->finish;
  1576. }
  1577. }
  1578. }
  1579. my $rc = $dbh->commit;
  1580. $dbh->disconnect;
  1581. $rc;
  1582. }
  1583. sub get_soparts {
  1584. my ($self, $myconfig, $form) = @_;
  1585. # connect to database
  1586. my $dbh = $form->dbconnect($myconfig);
  1587. my $id;
  1588. my $ref;
  1589. # store required items from selected sales orders
  1590. my $query = qq|SELECT p.id, oi.qty - oi.ship AS required,
  1591. p.assembly
  1592. FROM orderitems oi
  1593. JOIN parts p ON (p.id = oi.parts_id)
  1594. WHERE oi.trans_id = ?|;
  1595. my $sth = $dbh->prepare($query) || $form->dberror($query);
  1596. for (my $i = 1; $i <= $form->{rowcount}; $i++) {
  1597. if ($form->{"ndx_$i"}) {
  1598. $sth->execute($form->{"ndx_$i"});
  1599. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1600. &add_items_required("", $dbh, $form, $ref->{id}, $ref->{required}, $ref->{assembly});
  1601. }
  1602. $sth->finish;
  1603. }
  1604. }
  1605. $query = qq|SELECT current_date FROM defaults|;
  1606. ($form->{transdate}) = $dbh->selectrow_array($query);
  1607. # foreign exchange rates
  1608. &exchangerate_defaults($dbh, $form);
  1609. $dbh->disconnect;
  1610. }
  1611. sub add_items_required {
  1612. my ($self, $dbh, $form, $parts_id, $required, $assembly) = @_;
  1613. my $query;
  1614. my $sth;
  1615. my $ref;
  1616. if ($assembly) {
  1617. $query = qq|SELECT p.id, a.qty, p.assembly
  1618. FROM assembly a
  1619. JOIN parts p ON (p.id = a.parts_id)
  1620. WHERE a.id = $parts_id|;
  1621. $sth = $dbh->prepare($query);
  1622. $sth->execute || $form->dberror($query);
  1623. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1624. &add_items_required("", $dbh, $form, $ref->{id}, $required * $ref->{qty}, $ref->{assembly});
  1625. }
  1626. $sth->finish;
  1627. } else {
  1628. $query = qq|SELECT partnumber, description, lastcost
  1629. FROM parts
  1630. WHERE id = $parts_id|;
  1631. $sth = $dbh->prepare($query);
  1632. $sth->execute || $form->dberror($query);
  1633. $ref = $sth->fetchrow_hashref(NAME_lc);
  1634. for (keys %$ref) { $form->{orderitems}{$parts_id}{$_} = $ref->{$_} }
  1635. $sth->finish;
  1636. $form->{orderitems}{$parts_id}{required} += $required;
  1637. $query = qq|SELECT pv.partnumber, pv.leadtime, pv.lastcost, pv.curr,
  1638. pv.vendor_id, v.name
  1639. FROM partsvendor pv
  1640. JOIN vendor v ON (v.id = pv.vendor_id)
  1641. WHERE pv.parts_id = ?|;
  1642. $sth = $dbh->prepare($query) || $form->dberror($query);
  1643. # get cost and vendor
  1644. $sth->execute($parts_id);
  1645. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1646. for (keys %$ref) { $form->{orderitems}{$parts_id}{partsvendor}{$ref->{vendor_id}}{$_} = $ref->{$_} }
  1647. }
  1648. $sth->finish;
  1649. }
  1650. }
  1651. sub generate_orders {
  1652. my ($self, $myconfig, $form) = @_;
  1653. my $i;
  1654. my %a;
  1655. my $query;
  1656. my $sth;
  1657. for ($i = 1; $i <= $form->{rowcount}; $i++) {
  1658. for (qw(qty lastcost)) { $form->{"${_}_$i"} = $form->parse_amount($myconfig, $form->{"${_}_$i"}) }
  1659. if ($form->{"qty_$i"}) {
  1660. ($vendor, $vendor_id) = split /--/, $form->{"vendor_$i"};
  1661. if ($vendor_id) {
  1662. $a{$vendor_id}{$form->{"id_$i"}}{qty} += $form->{"qty_$i"};
  1663. for (qw(curr lastcost)) { $a{$vendor_id}{$form->{"id_$i"}}{$_} = $form->{"${_}_$i"} }
  1664. }
  1665. }
  1666. }
  1667. # connect to database
  1668. my $dbh = $form->dbconnect_noauto($myconfig);
  1669. # foreign exchange rates
  1670. &exchangerate_defaults($dbh, $form);
  1671. my $amount;
  1672. my $netamount;
  1673. my $curr = "";
  1674. my %tax;
  1675. my $taxincluded = 0;
  1676. my $vendor_id;
  1677. my $description;
  1678. my $unit;
  1679. my $sellprice;
  1680. foreach $vendor_id (keys %a) {
  1681. %tax = ();
  1682. $query = qq|SELECT v.curr, v.taxincluded, t.rate, c.accno
  1683. FROM vendor v
  1684. LEFT JOIN vendortax vt ON (v.id = vt.vendor_id)
  1685. LEFT JOIN tax t ON (t.chart_id = vt.chart_id)
  1686. LEFT JOIN chart c ON (c.id = t.chart_id)
  1687. WHERE v.id = $vendor_id|;
  1688. $sth = $dbh->prepare($query);
  1689. $sth->execute || $form->dberror($query);
  1690. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1691. $curr = $ref->{curr};
  1692. $taxincluded = $ref->{taxincluded};
  1693. $tax{$ref->{accno}} = $ref->{rate};
  1694. }
  1695. $sth->finish;
  1696. $curr ||= $form->{defaultcurrency};
  1697. $taxincluded *= 1;
  1698. my $uid = localtime;
  1699. $uid .= "$$";
  1700. $query = qq|INSERT INTO oe (ordnumber)
  1701. VALUES ('$uid')|;
  1702. $dbh->do($query) || $form->dberror($query);
  1703. $query = qq|SELECT id FROM oe
  1704. WHERE ordnumber = '$uid'|;
  1705. $sth = $dbh->prepare($query);
  1706. $sth->execute || $form->dberror($query);
  1707. my ($id) = $sth->fetchrow_array;
  1708. $sth->finish;
  1709. $amount = 0;
  1710. $netamount = 0;
  1711. foreach my $parts_id (keys %{ $a{$vendor_id} }) {
  1712. if (($form->{$curr} * $form->{$a{$vendor_id}{$parts_id}{curr}}) > 0) {
  1713. $sellprice = $a{$vendor_id}{$parts_id}{lastcost} / $form->{$curr} * $form->{$a{$vendor_id}{$parts_id}{curr}};
  1714. } else {
  1715. $sellprice = $a{$vendor_id}{$parts_id}{lastcost};
  1716. }
  1717. $sellprice = $form->round_amount($sellprice, 2);
  1718. my $linetotal = $form->round_amount($sellprice * $a{$vendor_id}{$parts_id}{qty}, 2);
  1719. $query = qq|SELECT p.description, p.unit, c.accno FROM parts p
  1720. LEFT JOIN partstax pt ON (p.id = pt.parts_id)
  1721. LEFT JOIN chart c ON (c.id = pt.chart_id)
  1722. WHERE p.id = $parts_id|;
  1723. $sth = $dbh->prepare($query);
  1724. $sth->execute || $form->dberror($query);
  1725. my $rate = 0;
  1726. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1727. $description = $ref->{description};
  1728. $unit = $ref->{unit};
  1729. $rate += $tax{$ref->{accno}};
  1730. }
  1731. $sth->finish;
  1732. $netamount += $linetotal;
  1733. if ($taxincluded) {
  1734. $amount += $linetotal;
  1735. } else {
  1736. $amount += $form->round_amount($linetotal * (1 + $rate), 2);
  1737. }
  1738. $description = $dbh->quote($description);
  1739. $unit = $dbh->quote($unit);
  1740. $query = qq|INSERT INTO orderitems (trans_id, parts_id, description,
  1741. qty, ship, sellprice, unit) VALUES
  1742. ($id, $parts_id, $description,
  1743. $a{$vendor_id}{$parts_id}{qty}, 0, $sellprice, $unit)|;
  1744. $dbh->do($query) || $form->dberror($query);
  1745. }
  1746. my $ordnumber = $form->update_defaults($myconfig, 'ponumber');
  1747. my $null;
  1748. my $employee_id;
  1749. my $department_id;
  1750. ($null, $employee_id) = $form->get_employee($dbh);
  1751. ($null, $department_id) = split /--/, $form->{department};
  1752. $department_id *= 1;
  1753. $query = qq|UPDATE oe SET
  1754. ordnumber = |.$dbh->quote($ordnumber).qq|,
  1755. transdate = current_date,
  1756. vendor_id = $vendor_id,
  1757. customer_id = 0,
  1758. amount = $amount,
  1759. netamount = $netamount,
  1760. taxincluded = '$taxincluded',
  1761. curr = '$curr',
  1762. employee_id = $employee_id,
  1763. department_id = '$department_id',
  1764. ponumber = |.$dbh->quote($form->{ponumber}).qq|
  1765. WHERE id = $id|;
  1766. $dbh->do($query) || $form->dberror($query);
  1767. }
  1768. my $rc = $dbh->commit;
  1769. $dbh->disconnect;
  1770. $rc;
  1771. }
  1772. sub consolidate_orders {
  1773. my ($self, $myconfig, $form) = @_;
  1774. # connect to database
  1775. my $dbh = $form->dbconnect_noauto($myconfig);
  1776. my $i;
  1777. my $id;
  1778. my $ref;
  1779. my %oe = ();
  1780. my $query = qq|SELECT * FROM oe
  1781. WHERE id = ?|;
  1782. my $sth = $dbh->prepare($query) || $form->dberror($query);
  1783. for ($i = 1; $i <= $form->{rowcount}; $i++) {
  1784. # retrieve order
  1785. if ($form->{"ndx_$i"}) {
  1786. $sth->execute($form->{"ndx_$i"});
  1787. $ref = $sth->fetchrow_hashref(NAME_lc);
  1788. $ref->{ndx} = $i;
  1789. $oe{oe}{$ref->{curr}}{$ref->{id}} = $ref;
  1790. $oe{vc}{$ref->{curr}}{$ref->{"$form->{vc}_id"}}++;
  1791. $sth->finish;
  1792. }
  1793. }
  1794. $query = qq|SELECT * FROM orderitems
  1795. WHERE trans_id = ?|;
  1796. $sth = $dbh->prepare($query) || $form->dberror($query);
  1797. foreach $curr (keys %{ $oe{oe} }) {
  1798. foreach $id (sort { $oe{oe}{$curr}{$a}->{ndx} <=> $oe{oe}{$curr}{$b}->{ndx} } keys %{ $oe{oe}{$curr} }) {
  1799. # retrieve order
  1800. $vc_id = $oe{oe}{$curr}{$id}->{"$form->{vc}_id"};
  1801. if ($oe{vc}{$oe{oe}{$curr}{$id}->{curr}}{$vc_id} > 1) {
  1802. push @{ $oe{orders}{$curr}{$vc_id} }, $id;
  1803. $sth->execute($id);
  1804. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1805. push @{ $oe{orderitems}{$curr}{$id} }, $ref;
  1806. }
  1807. $sth->finish;
  1808. }
  1809. }
  1810. }
  1811. my $ordnumber = $form->{ordnumber};
  1812. my $numberfld = ($form->{vc} eq 'customer') ? 'sonumber' : 'ponumber';
  1813. my ($department, $department_id) = $form->{department};
  1814. $department_id *= 1;
  1815. my $uid = localtime;
  1816. $uid .= "$$";
  1817. my @orderitems = ();
  1818. foreach $curr (keys %{ $oe{orders} }) {
  1819. foreach $vc_id (sort { $a <=> $b } keys %{ $oe{orders}{$curr} }) {
  1820. # the orders
  1821. @orderitems = ();
  1822. $form->{customer_id} = $form->{vendor_id} = 0;
  1823. $form->{"$form->{vc}_id"} = $vc_id;
  1824. $amount = 0;
  1825. $netamount = 0;
  1826. foreach $id (@{ $oe{orders}{$curr}{$vc_id} }) {
  1827. # header
  1828. $ref = $oe{oe}{$curr}{$id};
  1829. $amount += $ref->{amount};
  1830. $netamount += $ref->{netamount};
  1831. foreach $item (@{ $oe{orderitems}{$curr}{$id} }) {
  1832. push @orderitems, $item;
  1833. }
  1834. # close order
  1835. $query = qq|UPDATE oe SET
  1836. closed = '1'
  1837. WHERE id = $id|;
  1838. $dbh->do($query) || $form->dberror($query);
  1839. # reset shipped
  1840. $query = qq|UPDATE orderitems SET
  1841. ship = 0
  1842. WHERE trans_id = $id|;
  1843. $dbh->do($query) || $form->dberror($query);
  1844. }
  1845. $ordnumber ||= $form->update_defaults($myconfig, $numberfld, $dbh);
  1846. $query = qq|INSERT INTO oe (ordnumber)
  1847. VALUES ($uid)|;
  1848. $dbh->do($query) || $form->dberror($query);
  1849. $query = qq|SELECT id
  1850. FROM oe
  1851. WHERE ordnumber = '$uid'|;
  1852. ($id) = $dbh->selectrow_array($query);
  1853. $ref->{employee_id} *= 1;
  1854. $query = qq|UPDATE oe SET
  1855. ordnumber = |.$dbh->quote($ordnumber).qq|,
  1856. transdate = current_date,
  1857. vendor_id = $form->{vendor_id},
  1858. customer_id = $form->{customer_id},
  1859. amount = $amount,
  1860. netamount = $netamount,
  1861. reqdate = |.$form->dbquote($ref->{reqdate}, SQL_DATE).qq|,
  1862. taxincluded = '$ref->{taxincluded}',
  1863. shippingpoint = |.$dbh->quote($ref->{shippingpoint}).qq|,
  1864. notes = |.$dbh->quote($ref->{notes}).qq|,
  1865. curr = '$curr',
  1866. employee_id = $ref->{employee_id},
  1867. intnotes = |.$dbh->quote($ref->{intnotes}).qq|,
  1868. shipvia = |.$dbh->quote($ref->{shipvia}).qq|,
  1869. language_code = '$ref->{language_code}',
  1870. ponumber = |.$dbh->quote($form->{ponumber}).qq|,
  1871. department_id = $department_id
  1872. WHERE id = $id|;
  1873. $dbh->do($query) || $form->dberror($query);
  1874. # add items
  1875. foreach $item (@orderitems) {
  1876. for (qw(qty sellprice discount project_id ship)) { $item->{$_} *= 1 }
  1877. $query = qq|INSERT INTO orderitems (
  1878. trans_id, parts_id, description,
  1879. qty, sellprice, discount,
  1880. unit, reqdate, project_id,
  1881. ship, serialnumber, notes)
  1882. VALUES (
  1883. $id, $item->{parts_id}, |.$dbh->quote($item->{description}).qq|,
  1884. $item->{qty}, $item->{sellprice}, $item->{discount},
  1885. |.$dbh->quote($item->{unit}).qq|, |.$form->dbquote($item->{reqdate}, SQL_DATE).qq|, $item->{project_id},
  1886. $item->{ship}, |.$dbh->quote($item->{serialnumber}).qq|, |.$dbh->quote($item->{notes}).qq|)|;
  1887. $dbh->do($query) || $form->dberror($query);
  1888. }
  1889. }
  1890. }
  1891. $rc = $dbh->commit;
  1892. $dbh->disconnect;
  1893. $rc;
  1894. }
  1895. 1;