summaryrefslogtreecommitdiff
path: root/LedgerSMB/AA.pm
blob: c29652b0d5b4e6c1cc5a726917773905ae104d49 (plain)
  1. #=====================================================================
  2. # LedgerSMB
  3. # Small Medium Business Accounting software
  4. # http://www.ledgersmb.org/
  5. # Copyright (C) 2006
  6. # This work contains copyrighted information from a number of sources all used
  7. # with permission.
  8. #
  9. # This file contains source code included with or based on SQL-Ledger which
  10. # is Copyright Dieter Simader and DWS Systems Inc. 2000-2005 and licensed
  11. # under the GNU General Public License version 2 or, at your option, any later
  12. # version. For a full list including contact information of contributors,
  13. # maintainers, and copyright holders, see the CONTRIBUTORS file.
  14. #
  15. # Original Copyright Notice from SQL-Ledger 2.6.17 (before the fork):
  16. # Copyright (C) 2006
  17. #
  18. # Author: DWS Systems Inc.
  19. # Web: http://www.sql-ledger.org
  20. #
  21. # Contributors:
  22. #
  23. #
  24. # See COPYRIGHT file for copyright information
  25. #======================================================================
  26. #
  27. # This file has undergone whitespace cleanup.
  28. #
  29. #======================================================================
  30. #
  31. # AR/AP backend routines
  32. # common routines
  33. #
  34. #======================================================================
  35. package AA;
  36. use LedgerSMB::Sysconfig;
  37. sub post_transaction {
  38. my ( $self, $myconfig, $form ) = @_;
  39. # connect to database
  40. my $dbh = $form->{dbh};
  41. $form->{invnumber} = $form->update_defaults( $myconfig, $invnumber )
  42. unless $form->{invnumber};
  43. my $query;
  44. my $sth;
  45. my $null;
  46. ( $null, $form->{department_id} ) = split( /--/, $form->{department} );
  47. $form->{department_id} *= 1;
  48. my $ml = 1;
  49. my $table = 'ar';
  50. my $buysell = 'buy';
  51. my $ARAP = 'AR';
  52. my $invnumber = "sinumber";
  53. my $keepcleared;
  54. if ( $form->{vc} eq 'vendor' ) {
  55. $table = 'ap';
  56. $buysell = 'sell';
  57. $ARAP = 'AP';
  58. $ml = -1;
  59. $invnumber = "vinumber";
  60. }
  61. if ( $form->{currency} eq $form->{defaultcurrency} ) {
  62. $form->{exchangerate} = 1;
  63. }
  64. else {
  65. $exchangerate =
  66. $form->check_exchangerate( $myconfig, $form->{currency},
  67. $form->{transdate}, $buysell );
  68. $form->{exchangerate} =
  69. ($exchangerate)
  70. ? $exchangerate
  71. : $form->parse_amount( $myconfig, $form->{exchangerate} );
  72. }
  73. my @taxaccounts = split / /, $form->{taxaccounts};
  74. my $tax = 0;
  75. my $fxtax = 0;
  76. my $amount;
  77. my $diff;
  78. my %tax = ();
  79. my $accno;
  80. # add taxes
  81. foreach $accno (@taxaccounts) {
  82. $fxtax += $tax{fxamount}{$accno} =
  83. $form->parse_amount( $myconfig, $form->{"tax_$accno"} );
  84. $tax += $tax{fxamount}{$accno};
  85. push @{ $form->{acc_trans}{taxes} },
  86. {
  87. accno => $accno,
  88. amount => $tax{fxamount}{$accno},
  89. project_id => undef,
  90. fx_transaction => 0
  91. };
  92. $amount = $tax{fxamount}{$accno} * $form->{exchangerate};
  93. $tax{amount}{$accno} = $form->round_amount( $amount - $diff, 2 );
  94. $diff = $tax{amount}{$accno} - ( $amount - $diff );
  95. $amount = $tax{amount}{$accno} - $tax{fxamount}{$accno};
  96. $tax += $amount;
  97. if ( $form->{currency} ne $form->{defaultcurrency} ) {
  98. push @{ $form->{acc_trans}{taxes} },
  99. {
  100. accno => $accno,
  101. amount => $amount,
  102. project_id => undef,
  103. fx_transaction => 1
  104. };
  105. }
  106. }
  107. my %amount = ();
  108. my $fxinvamount = 0;
  109. for ( 1 .. $form->{rowcount} ) {
  110. $fxinvamount += $amount{fxamount}{$_} =
  111. $form->parse_amount( $myconfig, $form->{"amount_$_"} );
  112. }
  113. $form->{taxincluded} *= 1;
  114. my $i;
  115. my $project_id;
  116. my $cleared = 0;
  117. $diff = 0;
  118. # deduct tax from amounts if tax included
  119. for $i ( 1 .. $form->{rowcount} ) {
  120. if ( $amount{fxamount}{$i} ) {
  121. if ( $form->{taxincluded} ) {
  122. $amount =
  123. ($fxinvamount)
  124. ? $fxtax * $amount{fxamount}{$i} / $fxinvamount
  125. : 0;
  126. $amount{fxamount}{$i} -= $amount;
  127. }
  128. # multiply by exchangerate
  129. $amount = $amount{fxamount}{$i} * $form->{exchangerate};
  130. $amount{amount}{$i} = $form->round_amount( $amount - $diff, 2 );
  131. $diff = $amount{amount}{$i} - ( $amount - $diff );
  132. ( $null, $project_id ) = split /--/, $form->{"projectnumber_$i"};
  133. $project_id ||= undef;
  134. ($accno) = split /--/, $form->{"${ARAP}_amount_$i"};
  135. if ($keepcleared) {
  136. $cleared = ( $form->{"cleared_$i"} ) ? 1 : 0;
  137. }
  138. push @{ $form->{acc_trans}{lineitems} },
  139. {
  140. accno => $accno,
  141. amount => $amount{fxamount}{$i},
  142. project_id => $project_id,
  143. description => $form->{"description_$i"},
  144. cleared => $cleared,
  145. fx_transaction => 0
  146. };
  147. if ( $form->{currency} ne $form->{defaultcurrency} ) {
  148. $amount = $amount{amount}{$i} - $amount{fxamount}{$i};
  149. push @{ $form->{acc_trans}{lineitems} },
  150. {
  151. accno => $accno,
  152. amount => $amount,
  153. project_id => $project_id,
  154. description => $form->{"description_$i"},
  155. cleared => $cleared,
  156. fx_transaction => 1
  157. };
  158. }
  159. }
  160. }
  161. my $invnetamount = 0;
  162. for ( @{ $form->{acc_trans}{lineitems} } ) { $invnetamount += $_->{amount} }
  163. my $invamount = $invnetamount + $tax;
  164. # adjust paidaccounts if there is no date in the last row
  165. $form->{paidaccounts}--
  166. unless ( $form->{"datepaid_$form->{paidaccounts}"} );
  167. if ( $form->{vc} ne "customer" ) {
  168. $form->{vc} = "vendor";
  169. }
  170. my $paid = 0;
  171. my $fxamount;
  172. $diff = 0;
  173. # add payments
  174. for $i ( 1 .. $form->{paidaccounts} ) {
  175. $fxamount = $form->parse_amount( $myconfig, $form->{"paid_$i"} );
  176. if ($fxamount) {
  177. $paid += $fxamount;
  178. $paidamount = $fxamount * $form->{exchangerate};
  179. $amount = $form->round_amount( $paidamount - $diff, 2 );
  180. $diff = $amount - ( $paidamount - $diff );
  181. $form->{datepaid} = $form->{"datepaid_$i"};
  182. $paid{fxamount}{$i} = $fxamount;
  183. $paid{amount}{$i} = $amount;
  184. }
  185. }
  186. $fxinvamount += $fxtax unless $form->{taxincluded};
  187. $fxinvamount = $form->round_amount( $fxinvamount, 2 );
  188. $invamount = $form->round_amount( $invamount, 2 );
  189. $paid = $form->round_amount( $paid, 2 );
  190. $paid =
  191. ( $fxinvamount == $paid )
  192. ? $invamount
  193. : $form->round_amount( $paid * $form->{exchangerate}, 2 );
  194. $query = q|
  195. SELECT (SELECT value FROM defaults
  196. WHERE setting_key = 'fxgain_accno_id'),
  197. (SELECT value FROM defaults
  198. WHERE setting_key = 'fxloss_accno_id')|;
  199. my ( $fxgain_accno_id, $fxloss_accno_id ) = $dbh->selectrow_array($query);
  200. ( $null, $form->{employee_id} ) = split /--/, $form->{employee};
  201. unless ( $form->{employee_id} ) {
  202. ( $form->{employee}, $form->{employee_id} ) = $form->get_employee($dbh);
  203. }
  204. # check if id really exists
  205. if ( $form->{id} ) {
  206. my $id = $dbh->quote( $form->{id} );
  207. $keepcleared = 1;
  208. $query = qq|
  209. SELECT id
  210. FROM $table
  211. WHERE id = $id|;
  212. if ( $dbh->selectrow_array($query) ) {
  213. # delete detail records
  214. $query = qq|
  215. DELETE FROM acc_trans
  216. WHERE trans_id = $id|;
  217. $dbh->do($query) || $form->dberror($query);
  218. }
  219. }
  220. else {
  221. my $uid = localtime;
  222. $uid .= "$$";
  223. $query = qq|
  224. INSERT INTO $table (invnumber)
  225. VALUES ('$uid')|;
  226. $dbh->do($query) || $form->dberror($query);
  227. $query = qq|
  228. SELECT id FROM $table
  229. WHERE invnumber = '$uid'|;
  230. ( $form->{id} ) = $dbh->selectrow_array($query);
  231. }
  232. # record last payment date in ar/ap table
  233. $form->{datepaid} = $form->{transdate} unless $form->{datepaid};
  234. my $datepaid = ($paid) ? qq|'$form->{datepaid}'| : 'NOW';
  235. $query = qq|
  236. UPDATE $table
  237. SET invnumber = ?,
  238. ordnumber = ?,
  239. transdate = ?,
  240. $form->{vc}_id = ?,
  241. taxincluded = ?,
  242. amount = ?,
  243. duedate = ?,
  244. paid = ?,
  245. datepaid = ?,
  246. netamount = ?,
  247. curr = ?,
  248. notes = ?,
  249. department_id = ?,
  250. employee_id = ?,
  251. ponumber = ?
  252. WHERE id = ?
  253. |;
  254. my @queryargs = (
  255. $form->{invnumber}, $form->{ordnumber},
  256. $form->{transdate}, $form->{"$form->{vc}_id"},
  257. $form->{taxincluded}, $invamount,
  258. $form->{duedate}, $paid,
  259. $datepaid, $invnetamout,
  260. $form->{currency}, $form->{notes},
  261. $form->{department_id}, $form->{employee_id},
  262. $form->{ponumber}, $form->{id}
  263. );
  264. $dbh->prepare($query)->execute(@queryargs) || $form->dberror($query);
  265. if (defined $form->{approved}) {
  266. $query = qq| UPDATE $table SET approved = ? WHERE id = ?|;
  267. $dbh->prepare($query)->execute($form->{approved}, $form->{id}) ||
  268. $form->dberror($query);
  269. if (!$form->{approved}){
  270. if (not defined $form->{batch_id}){
  271. $form->error($locale->text('Batch ID Missing'));
  272. }
  273. $query = qq|
  274. INSERT INTO voucher (batch_id, trans_id) VALUES (?, ?)|;
  275. $dbh->prepare($query)->execute($form->{batch_id}, $form->{id}) ||
  276. $form->dberror($query);
  277. }
  278. }
  279. @queries = $form->run_custom_queries( $table, 'INSERT' );
  280. # update exchangerate
  281. my $buy = $form->{exchangerate};
  282. my $sell = 0;
  283. if ( $form->{vc} eq 'vendor' ) {
  284. $buy = 0;
  285. $sell = $form->{exchangerate};
  286. }
  287. if ( ( $form->{currency} ne $form->{defaultcurrency} ) && !$exchangerate ) {
  288. $form->update_exchangerate( $dbh, $form->{currency}, $form->{transdate},
  289. $buy, $sell );
  290. }
  291. my $ref;
  292. # add individual transactions
  293. foreach $ref ( @{ $form->{acc_trans}{lineitems} } ) {
  294. # insert detail records in acc_trans
  295. if ( $ref->{amount} ) {
  296. $query = qq|
  297. INSERT INTO acc_trans
  298. (trans_id, chart_id, amount,
  299. transdate, project_id, memo,
  300. fx_transaction, cleared)
  301. VALUES (?, (SELECT id FROM chart
  302. WHERE accno = ?),
  303. ?, ?, ?, ?, ?, ?)|;
  304. @queryargs = (
  305. $form->{id}, $ref->{accno},
  306. $ref->{amount} * $ml, $form->{transdate},
  307. $ref->{project_id}, $ref->{description},
  308. $ref->{fx_transaction}, $ref->{cleared}
  309. );
  310. $dbh->prepare($query)->execute(@queryargs)
  311. || $form->dberror($query);
  312. }
  313. }
  314. # save taxes
  315. foreach $ref ( @{ $form->{acc_trans}{taxes} } ) {
  316. if ( $ref->{amount} ) {
  317. $query = qq|
  318. INSERT INTO acc_trans
  319. (trans_id, chart_id, amount,
  320. transdate, fx_transaction)
  321. VALUES (?, (SELECT id FROM chart
  322. WHERE accno = ?),
  323. ?, ?, ?)|;
  324. @queryargs = (
  325. $form->{id}, $ref->{accno}, $ref->{amount} * $ml,
  326. $form->{transdate}, $ref->{fx_transaction}
  327. );
  328. $dbh->prepare($query)->execute(@queryargs)
  329. || $form->dberror($query);
  330. }
  331. }
  332. my $arap;
  333. # record ar/ap
  334. if ( ( $arap = $invamount ) ) {
  335. ($accno) = split /--/, $form->{$ARAP};
  336. $query = qq|
  337. INSERT INTO acc_trans
  338. (trans_id, chart_id, amount, transdate)
  339. VALUES (?, (SELECT id FROM chart
  340. WHERE accno = ?),
  341. ?, ?)|;
  342. @queryargs =
  343. ( $form->{id}, $accno, $invamount * -1 * $ml, $form->{transdate} );
  344. $dbh->prepare($query)->execute(@queryargs)
  345. || $form->dberror($query);
  346. }
  347. # if there is no amount force ar/ap
  348. if ( $fxinvamount == 0 ) {
  349. $arap = 1;
  350. }
  351. my $exchangerate;
  352. # add paid transactions
  353. for $i ( 1 .. $form->{paidaccounts} ) {
  354. if ( $paid{fxamount}{$i} ) {
  355. ($accno) = split( /--/, $form->{"${ARAP}_paid_$i"} );
  356. $form->{"datepaid_$i"} = $form->{transdate}
  357. unless ( $form->{"datepaid_$i"} );
  358. $exchangerate = 0;
  359. if ( $form->{currency} eq $form->{defaultcurrency} ) {
  360. $form->{"exchangerate_$i"} = 1;
  361. }
  362. else {
  363. $exchangerate =
  364. $form->check_exchangerate( $myconfig, $form->{currency},
  365. $form->{"datepaid_$i"}, $buysell );
  366. $form->{"exchangerate_$i"} =
  367. ($exchangerate)
  368. ? $exchangerate
  369. : $form->parse_amount( $myconfig,
  370. $form->{"exchangerate_$i"} );
  371. }
  372. # if there is no amount
  373. if ( $fxinvamount == 0 ) {
  374. $form->{exchangerate} = $form->{"exchangerate_$i"};
  375. }
  376. # ar/ap amount
  377. if ($arap) {
  378. ($accno) = split /--/, $form->{$ARAP};
  379. # add ar/ap
  380. $query = qq|
  381. INSERT INTO acc_trans
  382. (trans_id, chart_id,
  383. amount,transdate)
  384. VALUES (?, (SELECT id FROM chart
  385. WHERE accno = ?),
  386. ?, ?)|;
  387. @queryargs = (
  388. $form->{id}, $accno,
  389. $paid{amount}{$i} * $ml,
  390. $form->{"datepaid_$i"}
  391. );
  392. $dbh->prepare($query)->execute(@queryargs)
  393. || $form->dberror($query);
  394. }
  395. $arap = $paid{amount}{$i};
  396. # add payment
  397. if ( $paid{fxamount}{$i} ) {
  398. ($accno) = split /--/, $form->{"${ARAP}_paid_$i"};
  399. my $cleared = ( $form->{"cleared_$i"} ) ? 1 : 0;
  400. $amount = $paid{fxamount}{$i};
  401. $query = qq|
  402. INSERT INTO acc_trans
  403. (trans_id, chart_id, amount,
  404. transdate, source, memo,
  405. cleared)
  406. VALUES (?, (SELECT id FROM chart
  407. WHERE accno = ?),
  408. ?, ?, ?, ?, ?)|;
  409. @queryargs = (
  410. $form->{id}, $accno,
  411. $amount * -1 * $ml, $form->{"datepaid_$i"},
  412. $form->{"source_$i"}, $form->{"memo_$i"},
  413. $cleared
  414. );
  415. $dbh->prepare($query)->execute(@queryargs)
  416. || $form->dberror($query);
  417. if ( $form->{currency} ne $form->{defaultcurrency} ) {
  418. # exchangerate gain/loss
  419. $amount = (
  420. $form->round_amount(
  421. $paid{fxamount}{$i} * $form->{exchangerate}, 2 ) -
  422. $form->round_amount(
  423. $paid{fxamount}{$i} * $form->{"exchangerate_$i"}, 2
  424. )
  425. ) * -1;
  426. if ($amount) {
  427. my $accno_id =
  428. ( ( $amount * $ml ) > 0 )
  429. ? $fxgain_accno_id
  430. : $fxloss_accno_id;
  431. $query = qq|
  432. INSERT INTO acc_trans
  433. (trans_id,
  434. chart_id,
  435. amount,
  436. transdate,
  437. fx_transaction,
  438. cleared)
  439. VALUES (?, ?,
  440. ?,
  441. ?, '1', ?)|;
  442. @queryargs = (
  443. $form->{id}, $accno_id,
  444. $amount * $ml,
  445. $form->{"datepaid_$i"}, $cleared
  446. );
  447. $sth = $dbh->prepare($query);
  448. $sth->execute(@queryargs)
  449. || $form->dberror($query);
  450. }
  451. # exchangerate difference
  452. $amount = $paid{amount}{$i} - $paid{fxamount}{$i} + $amount;
  453. $query = qq|
  454. INSERT INTO acc_trans
  455. (trans_id, chart_id,
  456. amount,
  457. transdate,
  458. fx_transaction,
  459. cleared, source)
  460. VALUES (?, (SELECT id
  461. FROM chart
  462. WHERE accno
  463. = ?),
  464. ?, ?,
  465. '1', ?, ?)|;
  466. @queryargs = (
  467. $form->{id}, $accno,
  468. $amount * -1 * $ml,
  469. $form->{"datepaid_$i"},
  470. $cleared, $form->{"source_$i"}
  471. );
  472. $sth = $dbh->prepare($query);
  473. $sth->execute(@queryargs)
  474. || $form->dberror($query);
  475. }
  476. # update exchangerate record
  477. $buy = $form->{"exchangerate_$i"};
  478. $sell = 0;
  479. if ( $form->{vc} eq 'vendor' ) {
  480. $buy = 0;
  481. $sell = $form->{"exchangerate_$i"};
  482. }
  483. if ( ( $form->{currency} ne $form->{defaultcurrency} )
  484. && !$exchangerate )
  485. {
  486. $form->update_exchangerate( $dbh, $form->{currency},
  487. $form->{"datepaid_$i"},
  488. $buy, $sell );
  489. }
  490. }
  491. }
  492. }
  493. # save printed and queued
  494. $form->save_status($dbh);
  495. my %audittrail = (
  496. tablename => $table,
  497. reference => $form->{invnumber},
  498. formname => 'transaction',
  499. action => 'posted',
  500. id => $form->{id}
  501. );
  502. $form->audittrail( $dbh, "", \%audittrail );
  503. $form->save_recurring( $dbh, $myconfig );
  504. my $rc = $dbh->commit;
  505. $rc;
  506. }
  507. sub delete_transaction {
  508. my ( $self, $myconfig, $form ) = @_;
  509. # connect to database, turn AutoCommit off
  510. my $dbh = $form->{dbh};
  511. my $table = ( $form->{vc} eq 'customer' ) ? 'ar' : 'ap';
  512. my %audittrail = (
  513. tablename => $table,
  514. reference => $form->{invnumber},
  515. formname => 'transaction',
  516. action => 'deleted',
  517. id => $form->{id}
  518. );
  519. $form->audittrail( $dbh, "", \%audittrail );
  520. my $query = qq|DELETE FROM $table WHERE id = $form->{id}|;
  521. $dbh->do($query) || $form->dberror($query);
  522. $query = qq|DELETE FROM acc_trans WHERE trans_id = ?|;
  523. $dbh->prepare($query)->execute( $form->{id} ) || $form->dberror($query);
  524. # get spool files
  525. $query = qq|SELECT spoolfile
  526. FROM status
  527. WHERE trans_id = ?
  528. AND spoolfile IS NOT NULL|;
  529. my $sth = $dbh->prepare($query);
  530. $sth->execute( $form->{id} ) || $form->dberror($query);
  531. my $spoolfile;
  532. my @spoolfiles = ();
  533. while ( ($spoolfile) = $sth->fetchrow_array ) {
  534. push @spoolfiles, $spoolfile;
  535. }
  536. $sth->finish;
  537. $query = qq|DELETE FROM status WHERE trans_id = ?|;
  538. $dbh->prepare($query)->execute( $form->{id} ) || $form->dberror($query);
  539. # commit
  540. my $rc = $dbh->commit;
  541. if ($rc) {
  542. foreach $spoolfile (@spoolfiles) {
  543. unlink "${LedgerSMB::Sysconfig::spool}/$spoolfile" if $spoolfile;
  544. }
  545. }
  546. $rc;
  547. }
  548. sub transactions {
  549. my ( $self, $myconfig, $form ) = @_;
  550. # connect to database
  551. my $dbh = $form->{dbh};
  552. my $null;
  553. my $var;
  554. my $paid = "a.paid";
  555. my $ml = 1;
  556. my $ARAP = 'AR';
  557. my $table = 'ar';
  558. my $buysell = 'buy';
  559. my $acc_trans_join;
  560. my $acc_trans_flds;
  561. if ( $form->{vc} eq 'vendor' ) {
  562. $ml = -1;
  563. $ARAP = 'AP';
  564. $table = 'ap';
  565. $buysell = 'sell';
  566. }
  567. ( $form->{transdatefrom}, $form->{transdateto} ) =
  568. $form->from_to( $form->{year}, $form->{month}, $form->{interval} )
  569. if $form->{year} && $form->{month};
  570. my @paidargs = ();
  571. if ( $form->{outstanding} ) {
  572. $paid = qq|
  573. SELECT SUM(ac.amount) * -1 * $ml
  574. FROM acc_trans ac
  575. JOIN chart c ON (c.id = ac.chart_id)
  576. WHERE ac.trans_id = a.id
  577. AND (c.link LIKE '%${ARAP}_paid%'
  578. OR c.link = '')|;
  579. if ( $form->{transdateto} ) {
  580. $paid .= qq|
  581. AND ac.transdate <= ?|;
  582. push @paidargs, $form->{transdateto};
  583. }
  584. $form->{summary} = 1;
  585. }
  586. if ( !$form->{summary} ) {
  587. $acc_trans_flds = qq|
  588. , c.accno, ac.source,
  589. pr.projectnumber, ac.memo AS description,
  590. ac.amount AS linetotal,
  591. i.description AS linedescription|;
  592. $acc_trans_join = qq|
  593. JOIN acc_trans ac ON (a.id = ac.trans_id)
  594. JOIN chart c ON (c.id = ac.chart_id)
  595. LEFT JOIN project pr ON (pr.id = ac.project_id)
  596. LEFT JOIN invoice i ON (i.id = ac.invoice_id)|;
  597. }
  598. my $query = qq|
  599. SELECT a.id, a.invnumber, a.ordnumber, a.transdate,
  600. a.duedate, a.netamount, a.amount, ($paid) AS paid,
  601. a.invoice, a.datepaid, a.terms, a.notes,
  602. a.shipvia, a.shippingpoint, ee.name AS employee,
  603. vce.name,
  604. a.entity_id, a.till, me.name AS manager, a.curr,
  605. ex.$buysell AS exchangerate,
  606. d.description AS department,
  607. a.ponumber $acc_trans_flds
  608. FROM $table a
  609. JOIN $form->{vc} vc USING (entity_id)
  610. LEFT JOIN employee e ON (a.person_id = e.entity_id)
  611. LEFT JOIN employee m ON (e.managerid = m.id)
  612. JOIN entity ee ON (e.entity_id = ee.id)
  613. JOIN entity me ON (m.entity_id = me.id)
  614. JOIN entity vce ON (vc.entity_id = vce.id)
  615. LEFT JOIN exchangerate ex ON (ex.curr = a.curr
  616. AND ex.transdate = a.transdate)
  617. LEFT JOIN department d ON (a.department_id = d.id)
  618. $acc_trans_join|;
  619. my %ordinal = (
  620. id => 1,
  621. invnumber => 2,
  622. ordnumber => 3,
  623. transdate => 4,
  624. duedate => 5,
  625. datepaid => 10,
  626. shipvia => 13,
  627. shippingpoint => 14,
  628. employee => 15,
  629. name => 16,
  630. manager => 19,
  631. curr => 20,
  632. department => 22,
  633. ponumber => 23,
  634. accno => 24,
  635. source => 25,
  636. project => 26,
  637. description => 27
  638. );
  639. my @a = ( transdate, invnumber, name );
  640. push @a, "employee" if $form->{l_employee};
  641. push @a, "manager" if $form->{l_manager};
  642. my $sortorder = $form->sort_order( \@a, \%ordinal );
  643. my $where = "1 = 1";
  644. if ( $form->{"$form->{vc}_id"} ) {
  645. $where .= qq| AND a.entity_id = $form->{entity_id}|;
  646. }
  647. else {
  648. if ( $form->{ $form->{vc} } ) {
  649. $var = $dbh->quote( $form->like( lc $form->{ $form->{vc} } ) );
  650. $where .= " AND lower(vc.name) LIKE $var";
  651. }
  652. }
  653. for (qw(department employee)) {
  654. if ( $form->{$_} ) {
  655. ( $null, $var ) = split /--/, $form->{$_};
  656. $var = $dbh->quote($var);
  657. $where .= " AND a.${_}_id = $var";
  658. }
  659. }
  660. for (qw(invnumber ordnumber)) {
  661. if ( $form->{$_} ) {
  662. $var = $dbh->quote( $form->like( lc $form->{$_} ) );
  663. $where .= " AND lower(a.$_) LIKE $var";
  664. $form->{open} = $form->{closed} = 0;
  665. }
  666. }
  667. if ( $form->{partsid} ) {
  668. my $partsid = $dbh->quote( $form->{partsid} );
  669. $where .= " AND a.id IN (select trans_id FROM invoice
  670. WHERE parts_id = $partsid)";
  671. }
  672. for (qw(ponumber shipvia notes)) {
  673. if ( $form->{$_} ) {
  674. $var = $dbh->quote( $form->like( lc $form->{$_} ) );
  675. $where .= " AND lower(a.$_) LIKE $var";
  676. }
  677. }
  678. if ( $form->{description} ) {
  679. if ($acc_trans_flds) {
  680. $var = $dbh->quote( $form->like( lc $form->{description} ) );
  681. $where .= " AND lower(ac.memo) LIKE $var
  682. OR lower(i.description) LIKE $var";
  683. }
  684. else {
  685. $where .= " AND a.id = 0";
  686. }
  687. }
  688. if ( $form->{source} ) {
  689. if ($acc_trans_flds) {
  690. $var = $dbh->quote( $form->like( lc $form->{source} ) );
  691. $where .= " AND lower(ac.source) LIKE $var";
  692. }
  693. else {
  694. $where .= " AND a.id = 0";
  695. }
  696. }
  697. my $transdatefrom = $dbh->quote( $form->{transdatefrom} );
  698. $where .= " AND a.transdate >= $transdatefrom"
  699. if $form->{transdatefrom};
  700. my $transdateto = $dbh->quote( $form->{transdateto} );
  701. $where .= " AND a.transdate <= $transdateto" if $form->{transdateto};
  702. if ( $form->{open} || $form->{closed} ) {
  703. unless ( $form->{open} && $form->{closed} ) {
  704. $where .= " AND a.amount != a.paid" if ( $form->{open} );
  705. $where .= " AND a.amount = a.paid" if ( $form->{closed} );
  706. }
  707. }
  708. if ( $form->{till} ne "" ) {
  709. $where .= " AND a.invoice = '1'
  710. AND a.till = $form->{till}";
  711. if ( $myconfig->{role} eq 'user' ) {
  712. my $login = $dbh->quote( $form->{login} );
  713. $where .= " AND e.login = $login";
  714. }
  715. }
  716. if ( $form->{$ARAP} ) {
  717. my ($accno) = split /--/, $form->{$ARAP};
  718. $accno = $dbh->quote($accno);
  719. $where .= qq|
  720. AND a.id IN (SELECT ac.trans_id
  721. FROM acc_trans ac
  722. JOIN chart c ON (c.id = ac.chart_id)
  723. WHERE a.id = ac.trans_id
  724. AND c.accno = $accno)|;
  725. }
  726. if ( $form->{description} ) {
  727. $var = $dbh->quote( $form->like( lc $form->{description} ) );
  728. $where .= qq|
  729. AND (a.id IN (SELECT DISTINCT trans_id
  730. FROM acc_trans
  731. WHERE lower(memo) LIKE '$var')
  732. OR a.id IN
  733. (SELECT DISTINCT trans_id
  734. FROM invoice
  735. WHERE lower(description)
  736. LIKE '$var'))|;
  737. }
  738. if ($form->{invoice_type}) {
  739. if ( $form->{invoice_type} == 2 ) {
  740. $where .= qq|
  741. AND a.on_hold = 'f'
  742. |;
  743. }
  744. if ($form->{invoice_type} == 3) {
  745. $where .= qq|
  746. AND a.on_hold = 't'
  747. |;
  748. }
  749. }
  750. # the third state, all invoices, sets no explicit toggles. It just selects them all, as normal.
  751. $query .= "WHERE $where
  752. ORDER BY $sortorder";
  753. my $sth = $dbh->prepare($query);
  754. $sth->execute(@paidargs) || $form->dberror($query);
  755. while ( my $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  756. $form->db_parse_numeric(sth => $sth, hashref => $ref);
  757. $ref->{exchangerate} = 1 unless $ref->{exchangerate};
  758. if ( $ref->{linetotal} <= 0 ) {
  759. $ref->{debit} = $ref->{linetotal} * -1;
  760. $ref->{credit} = 0;
  761. }
  762. else {
  763. $ref->{debit} = 0;
  764. $ref->{credit} = $ref->{linetotal};
  765. }
  766. if ( $ref->{invoice} ) {
  767. $ref->{description} ||= $ref->{linedescription};
  768. }
  769. if ( $form->{outstanding} ) {
  770. next
  771. if $form->round_amount( $ref->{amount}, 2 ) ==
  772. $form->round_amount( $ref->{paid}, 2 );
  773. }
  774. push @{ $form->{transactions} }, $ref;
  775. }
  776. $sth->finish;
  777. $dbh->commit;
  778. }
  779. # this is used in IS, IR to retrieve the name
  780. sub get_name {
  781. my ( $self, $myconfig, $form ) = @_;
  782. # sanitize $form->{vc}
  783. if ( $form->{vc} ne 'customer' ) {
  784. $form->{vc} = 'vendor';
  785. }
  786. else {
  787. $form->{vc} = 'customer';
  788. }
  789. # connect to database
  790. my $dbh = $form->{dbh};
  791. my $dateformat = $myconfig->{dateformat};
  792. if ( $myconfig->{dateformat} !~ /^y/ ) {
  793. my @a = split /\W/, $form->{transdate};
  794. $dateformat .= "yy" if ( length $a[2] > 2 );
  795. }
  796. if ( $form->{transdate} !~ /\W/ ) {
  797. $dateformat = 'yyyymmdd';
  798. }
  799. my $duedate;
  800. $dateformat = $dbh->quote($dateformat);
  801. my $tdate = $dbh->quote( $form->{transdate} );
  802. $duedate = ( $form->{transdate} )
  803. ? "to_date($tdate, $dateformat)
  804. + c.terms"
  805. : "current_date + c.terms";
  806. $form->{"$form->{vc}_id"} *= 1;
  807. # get customer/vendor
  808. my $query = qq|
  809. SELECT entity.name AS $form->{vc}, c.discount,
  810. c.creditlimit,
  811. c.terms, c.taxincluded,
  812. c.curr AS currency,
  813. c.language_code, $duedate AS duedate,
  814. b.discount AS tradediscount,
  815. b.description AS business
  816. FROM $form->{vc} c
  817. JOIN entity ON (entity.id = c.entity_id)
  818. LEFT JOIN business b ON (b.id = c.business_id)
  819. WHERE c.entity_id = ?|;
  820. # TODO: Add location join
  821. @queryargs = ( $form->{"$form->{vc}_id"} );
  822. my $sth = $dbh->prepare($query);
  823. $sth->execute(@queryargs) || $form->dberror($query);
  824. $ref = $sth->fetchrow_hashref(NAME_lc);
  825. $form->db_parse_numeric(sth => $sth, hashref => $ref);
  826. if ( $form->{id} ) {
  827. for (qw(currency employee employee_id intnotes)) {
  828. delete $ref->{$_};
  829. }
  830. }
  831. for ( keys %$ref ) { $form->{$_} = $ref->{$_} }
  832. $sth->finish;
  833. # TODO: Retrieve contact records
  834. my $buysell = ( $form->{vc} eq 'customer' ) ? "buy" : "sell";
  835. # if no currency use defaultcurrency
  836. $form->{currency} =
  837. ( $form->{currency} )
  838. ? $form->{currency}
  839. : $form->{defaultcurrency};
  840. $form->{exchangerate} = 0
  841. if $form->{currency} eq $form->{defaultcurrency};
  842. if ( $form->{transdate}
  843. && ( $form->{currency} ne $form->{defaultcurrency} ) )
  844. {
  845. $form->{exchangerate} =
  846. $form->get_exchangerate( $dbh, $form->{currency}, $form->{transdate},
  847. $buysell );
  848. }
  849. $form->{forex} = $form->{exchangerate};
  850. # if no employee, default to login
  851. ( $form->{employee}, $form->{employee_id} ) = $form->get_employee($dbh)
  852. unless $form->{employee_id};
  853. my $arap = ( $form->{vc} eq 'customer' ) ? 'ar' : 'ap';
  854. my $ARAP = uc $arap;
  855. $form->{creditremaining} = $form->{creditlimit};
  856. $query = qq|
  857. SELECT SUM(amount - paid)
  858. FROM $arap
  859. WHERE id = ?|;
  860. $sth = $dbh->prepare($query);
  861. $sth->execute( $form->{"$form->{vc}_id"} )
  862. || $form->dberror($query);
  863. ( $form->{creditremaining} ) -= $sth->fetchrow_array;
  864. $sth->finish;
  865. if ( $form->{vc} ne "customer" ) {
  866. $form->{vc} = 'vendor';
  867. }
  868. $query = qq|
  869. SELECT o.amount, (SELECT e.$buysell FROM exchangerate e
  870. WHERE e.curr = o.curr
  871. AND e.transdate = o.transdate)
  872. FROM oe o
  873. WHERE o.entity_id =
  874. (select entity_id from $form->{vc} WHERE id = ?)
  875. AND o.quotation = '0' AND o.closed = '0'|;
  876. $sth = $dbh->prepare($query);
  877. $sth->execute( $form->{"$form->{vc}_id"} ) || $form->dberror($query);
  878. while ( my @ref = $sth->fetchrow_array ) {
  879. $form->db_parse_numeric(sth => $sth, arrayref => \@ref);
  880. my ($amount, $exch) = @ref;
  881. $exch = 1 unless $exch;
  882. $form->{creditremaining} -= $amount * $exch;
  883. }
  884. $sth->finish;
  885. # get shipto if we did not converted an order or invoice
  886. if ( !$form->{shipto} ) {
  887. for (
  888. qw(shiptoname shiptoaddress1 shiptoaddress2
  889. shiptocity shiptostate shiptozipcode
  890. shiptocountry shiptocontact shiptophone
  891. shiptofax shiptoemail)
  892. )
  893. {
  894. delete $form->{$_};
  895. }
  896. ## needs fixing (SELECT *)
  897. $query = qq|
  898. SELECT *
  899. FROM shipto
  900. WHERE trans_id = $form->{"$form->{vc}_id"}|;
  901. $sth = $dbh->prepare($query);
  902. $sth->execute || $form->dberror($query);
  903. $ref = $sth->fetchrow_hashref(NAME_lc);
  904. for ( keys %$ref ) { $form->{$_} = $ref->{$_} }
  905. $sth->finish;
  906. }
  907. # get taxes
  908. $query = qq|
  909. SELECT c.accno
  910. FROM chart c
  911. JOIN $form->{vc}tax ct ON (ct.chart_id = c.id)
  912. WHERE ct.$form->{vc}_id = ?|;
  913. $sth = $dbh->prepare($query);
  914. $sth->execute( $form->{"$form->{vc}_id"} ) || $form->dberror($query);
  915. my %tax;
  916. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  917. $tax{ $ref->{accno} } = 1;
  918. }
  919. $sth->finish;
  920. $transdate = $dbh->quote( $form->{transdate} );
  921. my $where = qq|AND (t.validto >= $transdate OR t.validto IS NULL)|
  922. if $form->{transdate};
  923. # get tax rates and description
  924. $query = qq|
  925. SELECT c.accno, c.description, t.rate, t.taxnumber
  926. FROM chart c
  927. JOIN tax t ON (c.id = t.chart_id)
  928. WHERE c.link LIKE '%${ARAP}_tax%'
  929. $where
  930. ORDER BY accno, validto|;
  931. $sth = $dbh->prepare($query);
  932. $sth->execute || $form->dberror($query);
  933. $form->{taxaccounts} = "";
  934. my %a = ();
  935. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  936. $form->db_parse_numeric(sth => $sth, hashref => $hashref);
  937. if ( $tax{ $ref->{accno} } ) {
  938. if ( not exists $a{ $ref->{accno} } ) {
  939. for (qw(rate description taxnumber)) {
  940. $form->{"$ref->{accno}_$_"} = $ref->{$_};
  941. }
  942. $form->{taxaccounts} .= "$ref->{accno} ";
  943. $a{ $ref->{accno} } = 1;
  944. }
  945. }
  946. }
  947. $sth->finish;
  948. chop $form->{taxaccounts};
  949. # setup last accounts used for this customer/vendor
  950. if ( !$form->{id} && $form->{type} !~ /_(order|quotation)/ ) {
  951. $query = qq|
  952. SELECT c.accno, c.description, c.link,
  953. c.category,
  954. ac.project_id,
  955. a.department_id
  956. FROM chart c
  957. JOIN acc_trans ac ON (ac.chart_id = c.id)
  958. JOIN $arap a ON (a.id = ac.trans_id)
  959. WHERE a.entity_id = ?
  960. AND a.id = (SELECT max(id)
  961. FROM $arap
  962. WHERE entity_id =
  963. ?)
  964. |;
  965. $sth = $dbh->prepare($query);
  966. $sth->execute( $form->{"$form->{vc}_id"}, $form->{"$form->{vc}_id"} )
  967. || $form->dberror($query);
  968. my $i = 0;
  969. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  970. $form->{department_id} = $ref->{department_id};
  971. if ( $ref->{link} =~ /_amount/ ) {
  972. $i++;
  973. $form->{"$form->{ARAP}_amount_$i"} =
  974. "$ref->{accno}--$ref->{description}"
  975. if $ref->{accno};
  976. $form->{"projectnumber_$i"} =
  977. "$ref->{projectnumber}--" . "$ref->{project_id}"
  978. if $ref->{project_id};
  979. }
  980. if ( $ref->{link} eq $form->{ARAP} ) {
  981. $form->{ $form->{ARAP} } = $form->{"$form->{ARAP}_1"} =
  982. "$ref->{accno}--" . "$ref->{description}"
  983. if $ref->{accno};
  984. }
  985. }
  986. $sth->finish;
  987. $query = "select description from department where id = ?";
  988. $sth = $dbh->prepare($query);
  989. $sth->execute($form->{department_id});
  990. ($form->{department}) = $sth->fetchrow_array;
  991. $form->{rowcount} = $i if ( $i && !$form->{type} );
  992. }
  993. $dbh->commit;
  994. }
  995. 1;