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