summaryrefslogtreecommitdiff
path: root/LedgerSMB/CT.pm
blob: e9497b57d6c5eecd891ea725da669a6d7fd23182 (plain)
  1. #=====================================================================
  2. # LedgerSMB
  3. # Small Medium Business Accounting software
  4. # http://www.ledgersmb.org/
  5. #
  6. # Copyright (C) 2006
  7. # This work contains copyrighted information from a number of sources all used
  8. # with permission.
  9. #
  10. # This file contains source code included with or based on SQL-Ledger which
  11. # is Copyright Dieter Simader and DWS Systems Inc. 2000-2005 and licensed
  12. # under the GNU General Public License version 2 or, at your option, any later
  13. # version. For a full list including contact information of contributors,
  14. # maintainers, and copyright holders, see the CONTRIBUTORS file.
  15. #
  16. # Original Copyright Notice from SQL-Ledger 2.6.17 (before the fork):
  17. # Copyright (C) 2000
  18. #
  19. # Author: DWS Systems Inc.
  20. # Web: http://www.sql-ledger.org
  21. #
  22. # Contributors:
  23. #
  24. #
  25. #======================================================================
  26. #
  27. # This file has undergone whitespace cleanup.
  28. #
  29. #======================================================================
  30. #
  31. # backend code for customers and vendors
  32. #
  33. #======================================================================
  34. package CT;
  35. sub create_links {
  36. my ( $self, $myconfig, $form ) = @_;
  37. my $dbh = $form->{dbh};
  38. my $query;
  39. my $sth;
  40. my $ref;
  41. my $arap = ( $form->{db} eq 'customer' ) ? "ar" : "ap";
  42. my $ARAP = uc $arap;
  43. if ( $form->{id} ) {
  44. $query = qq|
  45. SELECT ct.*, b.description AS business, s.*,
  46. e.name AS employee,
  47. g.pricegroup AS pricegroup,
  48. l.description AS language, ct.curr
  49. FROM $form->{db} ct
  50. LEFT JOIN business b ON (ct.business_id = b.id)
  51. LEFT JOIN shipto s ON (ct.id = s.trans_id)
  52. LEFT JOIN employee e ON (ct.employee_id = e.id)
  53. LEFT JOIN pricegroup g ON (g.id = ct.pricegroup_id)
  54. LEFT JOIN language l ON (l.code = ct.language_code)
  55. WHERE ct.id = ?|;
  56. $sth = $dbh->prepare($query);
  57. $sth->execute( $form->{id} ) || $form->dberror($query);
  58. $ref = $sth->fetchrow_hashref(NAME_lc);
  59. for ( keys %$ref ) { $form->{$_} = $ref->{$_} }
  60. $sth->finish;
  61. # check if it is orphaned
  62. $query = qq|
  63. SELECT a.id
  64. FROM $arap a
  65. JOIN $form->{db} ct ON (a.$form->{db}_id = ct.id)
  66. WHERE ct.id = ?
  67. UNION
  68. SELECT a.id
  69. FROM oe a
  70. JOIN $form->{db} ct ON (a.$form->{db}_id = ct.id)
  71. WHERE ct.id = ?|;
  72. $sth = $dbh->prepare($query);
  73. $sth->execute( $form->{id}, $form->{id} )
  74. || $form->dberror($query);
  75. unless ( $sth->fetchrow_array ) {
  76. $form->{status} = "orphaned";
  77. }
  78. $sth->finish;
  79. # get taxes for customer/vendor
  80. $query = qq|
  81. SELECT c.accno
  82. FROM chart c
  83. JOIN $form->{db}tax t ON (t.chart_id = c.id)
  84. WHERE t.$form->{db}_id = ?|;
  85. $sth = $dbh->prepare($query);
  86. $sth->execute( $form->{id} ) || $form->dberror($query);
  87. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  88. $form->{tax}{ $ref->{accno} }{taxable} = 1;
  89. }
  90. $sth->finish;
  91. }
  92. else {
  93. ( $form->{employee}, $form->{employee_id} ) = $form->get_employee($dbh);
  94. $query = qq|SELECT current_date|;
  95. ( $form->{startdate} ) = $dbh->selectrow_array($query);
  96. }
  97. # get tax labels
  98. $query = qq|
  99. SELECT DISTINCT c.accno, c.description
  100. FROM chart c
  101. JOIN tax t ON (t.chart_id = c.id)
  102. WHERE c.link LIKE ?
  103. ORDER BY c.accno|;
  104. $sth = $dbh->prepare($query);
  105. $sth->execute("%${ARAP}_tax%") || $form->dberror($query);
  106. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  107. $form->{taxaccounts} .= "$ref->{accno} ";
  108. $form->{tax}{ $ref->{accno} }{description} = $ref->{description};
  109. }
  110. $sth->finish;
  111. chop $form->{taxaccounts};
  112. # get business types ## needs fixing, this is bad (SELECT * ...) with order by 2. Yuck
  113. $query = qq|
  114. SELECT *
  115. FROM business
  116. ORDER BY 2|;
  117. $sth = $dbh->prepare($query);
  118. $sth->execute || $form->dberror($query);
  119. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  120. push @{ $form->{all_business} }, $ref;
  121. }
  122. $sth->finish;
  123. # employees/salespersons
  124. $form->all_employees( $myconfig, $dbh, undef,
  125. ( $form->{vc} eq 'customer' )
  126. ? 1
  127. : 0 );
  128. # get language ## needs fixing, this is bad (SELECT * ...) with order by 2. Yuck
  129. $query = qq|
  130. SELECT *
  131. FROM language
  132. ORDER BY 2|;
  133. $sth = $dbh->prepare($query);
  134. $sth->execute || $form->dberror($query);
  135. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  136. push @{ $form->{all_language} }, $ref;
  137. }
  138. $sth->finish;
  139. # get pricegroups ## needs fixing, this is bad (SELECT * ...) with order by 2. Yuck
  140. $query = qq|
  141. SELECT *
  142. FROM pricegroup
  143. ORDER BY 2|;
  144. $sth = $dbh->prepare($query);
  145. $sth->execute || $form->dberror($query);
  146. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  147. push @{ $form->{all_pricegroup} }, $ref;
  148. }
  149. $sth->finish;
  150. # get currencies
  151. $query = qq|
  152. SELECT value AS currencies
  153. FROM defaults
  154. WHERE setting_key = 'curr'|;
  155. ( $form->{currencies} ) = $dbh->selectrow_array($query);
  156. $dbh->commit;
  157. }
  158. sub _save_vc {
  159. ($form) = @_;
  160. my $dbh = $form->{dbh};
  161. my $updated = 0;
  162. if ($form->{vc} eq 'customer'){
  163. $form->{vc} = 'customer';
  164. $form->{entity_class} = 2;
  165. } else {
  166. $form->{vc} = 'vendor';
  167. $form->{entity_class} = 1;
  168. }
  169. # this should really all be replaced by an upsert.
  170. if ( $form->{id} ) {
  171. # This module is depricated, so we are just going to throw an error here
  172. $form->error("Updating $form->{vc} not supported. ".
  173. "Please wait for us to move to the new codebase.");
  174. }
  175. if (!$updated){
  176. # Creating Entity
  177. ($form->{entity_id}) = $dbh->selectrow_array("SELECT nextval('entity_id_seq')");
  178. $query = qq|INSERT INTO entity (id, name, entity_class) VALUES (?, ?,?)|;
  179. $sth = $dbh->prepare($query);
  180. $sth->execute($form->{entity_id}, $form->{name}, $form->{entity_class});
  181. $sth->finish;
  182. # Creating LOCATION
  183. ($form->{location_id}) =
  184. $dbh->selectrow_array("SELECT nextval('location_id_seq')");
  185. $query = qq|
  186. INSERT INTO location
  187. (id, line_one, line_two, city_province, mail_code,
  188. country_id, location_class, created)
  189. VALUES
  190. (?, ?, ?, ?, ?,
  191. (SELECT id FROM country
  192. WHERE short_name = ? OR name = ?),
  193. 1, current_date)
  194. |; # location class 1 is Billing. This is a sensible default.
  195. $sth = $dbh->prepare($query);
  196. $sth->execute($form->{location_id}, $form->{address1}, $form->{address2},
  197. "$form->{city}, $form->{state}", $form->{zipcode},
  198. $form->{country}, $form->{country}
  199. ) || $form->dberror($query);
  200. #Creating company
  201. # Removed entity_class_id,
  202. # removed primary_location_id,
  203. # added sic_code ~Aurynn
  204. $query = qq|
  205. INSERT INTO company
  206. (entity_id, legal_name, tax_id, sic_code)
  207. VALUES
  208. (?, ?, ?, ?)
  209. |;
  210. $sth = $dbh->prepare($query) || $form->dberror($query);
  211. $sth->execute($form->{entity_id}, # $form->{entity_class}, # removed entity_class_id ~Aurynn
  212. $form->{name},
  213. # $form->{location_id}, # removed by ~aurynn
  214. $form->{taxnumber},
  215. $form->{sic_code});
  216. # Creating entity_metadata record, replacing customer and vendor.
  217. $query = qq|
  218. INSERT INTO entity_credit_account
  219. (entity_id, entity_class, discount, taxincluded, creditlimit,
  220. terms, meta_number, cc, bcc, business_id,
  221. language_code, pricegroup_id, curr, startdate,
  222. enddate)
  223. VALUES (?, ?, ?, ?, ?,
  224. ?, ?, ?, ?,
  225. ?, ?, ?, ?,
  226. ?, ?)|;
  227. $sth = $dbh->prepare($query);
  228. $sth->execute(
  229. $form->{entity_id}, $form->{entity_class}, $form->{discount},
  230. $form->{taxincluded}, $form->{creditlimit},
  231. $form->{terms}, $form->{"$form->{db}number"}, $form->{cc},
  232. $form->{bcc}, $form->{business_id},
  233. $form->{language_code}, $form->{pricegroup_id}, $form->{curr},
  234. $form->{startdate} || undef, $form->{enddate} || undef,
  235. ) || $form->dberror($query);
  236. $query = qq|
  237. INSERT INTO entity_bank_account (entity_id, bic, iban)
  238. VALUES (?,?,?)
  239. |;
  240. $sth = $dbh->prepare($query);
  241. $sth->execute($form->{entity_id}, $form->{bic}, $form->{iban}) ||
  242. $form->dberror($query);
  243. }
  244. }
  245. sub save_customer {
  246. my ( $self, $myconfig, $form ) = @_;
  247. # connect to databaseµ
  248. my $dbh = $form->{dbh};
  249. my $query;
  250. my $sth;
  251. my $null;
  252. $form->{vc} = 'customer';
  253. # remove double spaces
  254. $form->{name} =~ s/ / /g;
  255. # remove double minus and minus at the end
  256. $form->{name} =~ s/--+/-/g;
  257. $form->{name} =~ s/-+$//;
  258. # assign value discount, terms, creditlimit
  259. $form->{discount} = $form->parse_amount( $myconfig, $form->{discount} );
  260. $form->{discount} /= 100;
  261. $form->{terms} *= 1;
  262. $form->{taxincluded} *= 1;
  263. $form->{creditlimit} =
  264. $form->parse_amount( $myconfig, $form->{creditlimit} );
  265. if ( !$form->{creditlimit} ) {
  266. $form->{creditlimit} = 0;
  267. }
  268. &_save_vc($form);
  269. # save taxes
  270. foreach $item ( split / /, $form->{taxaccounts} ) {
  271. if ( $form->{"tax_$item"} ) {
  272. $query = qq|
  273. INSERT INTO customertax (customer_id, chart_id)
  274. VALUES (?, (SELECT id
  275. FROM chart
  276. WHERE accno = ?))|;
  277. $sth = $dbh->prepare($query);
  278. $sth->execute( $form->{id}, $item )
  279. || $form->dberror($query);
  280. }
  281. }
  282. # add shipto
  283. $form->add_shipto( $dbh, $form->{id} );
  284. $dbh->commit;
  285. }
  286. sub save_vendor {
  287. my ( $self, $myconfig, $form ) = @_;
  288. # connect to database
  289. my $dbh = $form->{dbh};
  290. my $query;
  291. my $sth;
  292. my $null;
  293. # remove double spaces
  294. $form->{name} =~ s/ / /g;
  295. # remove double minus and minus at the end
  296. $form->{name} =~ s/--+/-/g;
  297. $form->{name} =~ s/-+$//;
  298. $form->{discount} = $form->parse_amount( $myconfig, $form->{discount} );
  299. $form->{discount} /= 100;
  300. $form->{terms} *= 1;
  301. $form->{taxincluded} *= 1;
  302. $form->{creditlimit} =
  303. $form->parse_amount( $myconfig, $form->{creditlimit} );
  304. &_save_vc($form);
  305. # save taxes
  306. foreach $item ( split / /, $form->{taxaccounts} ) {
  307. if ( $form->{"tax_$item"} ) {
  308. $query = qq|
  309. INSERT INTO vendortax (vendor_id, chart_id)
  310. VALUES (?, (SELECT id
  311. FROM chart
  312. WHERE accno = ?))|;
  313. $sth = $dbh->prepare($query);
  314. $sth->execute( $form->{id}, $item )
  315. || $form->dberror($query);
  316. }
  317. }
  318. # add shipto
  319. $form->add_shipto( $dbh, $form->{id} );
  320. $dbh->commit;
  321. }
  322. sub delete {
  323. my ( $self, $myconfig, $form ) = @_;
  324. # connect to database
  325. my $dbh = $form->{dbh};
  326. # delete customer/vendor
  327. my $query = qq|DELETE FROM $form->{db}
  328. WHERE id = ?|;
  329. $sth = $dbh->prepare($query);
  330. $sth->execute( $form->{id} ) || $form->dberror($query);
  331. $dbh->commit;
  332. }
  333. sub search {
  334. my ( $self, $myconfig, $form ) = @_;
  335. # connect to database
  336. my $dbh = $form->{dbh};
  337. my $where = "1 = 1";
  338. $form->{sort} = ( $form->{sort} ) ? $form->{sort} : "name";
  339. my @a = qw(name);
  340. my $sortorder = $form->sort_order( \@a );
  341. my $var;
  342. my $item;
  343. @a = ("$form->{db}number");
  344. push @a, qw(name contact city state zipcode country notes phone email);
  345. if ( $form->{employee} ) {
  346. $var = $dbh->quote($form->like(lc $form->{employee}));
  347. $where .= " AND lower(e.name) LIKE $var";
  348. }
  349. foreach $item (@a) {
  350. if ( $form->{$item} ne "" ) {
  351. $var = $dbh->quote($form->like( lc $form->{$item}) );
  352. $where .= " AND lower(ct.$item) LIKE $var";
  353. }
  354. }
  355. if ( $form->{address} ne "" ) {
  356. $var = $dbh->quote( $form->like( lc $form->{address} ) );
  357. $where .=
  358. " AND (lower(ct.address1) ILIKE $var)";
  359. }
  360. if ( $form->{startdatefrom} ) {
  361. $where .=
  362. " AND ct.startdate >= " . $dbh->quote( $form->{startdatefrom} );
  363. }
  364. if ( $form->{startdateto} ) {
  365. $where .= " AND ct.startdate <= " . $dbh->quote( $form->{startdateto} );
  366. }
  367. if ( $form->{status} eq 'active' ) {
  368. $where .= " AND ct.enddate IS NULL";
  369. }
  370. if ( $form->{status} eq 'inactive' ) {
  371. $where .= " AND ct.enddate <= current_date";
  372. }
  373. if ( $form->{status} eq 'orphaned' ) {
  374. $where .= qq|
  375. AND ct.id NOT IN (SELECT o.$form->{db}_id
  376. FROM oe o, $form->{db} vc
  377. WHERE vc.id = o.$form->{db}_id)|;
  378. if ( $form->{db} =~ /(^customer$|^vendor$)/ ) {
  379. $where .= qq| AND ct.id NOT IN (SELECT a.entity_id
  380. FROM ar a, customer vc
  381. WHERE vc.entity_id = a.entity_id)|;
  382. }
  383. $form->{l_invnumber} = $form->{l_ordnumber} = $form->{l_quonumber} = "";
  384. }
  385. my $query = qq|
  386. SELECT ct.*, b.description AS business,
  387. e.name AS employee, g.pricegroup,
  388. l.description AS language, m.name AS manager
  389. FROM $form->{db} ct
  390. LEFT JOIN business b ON (ct.business_id = b.id)
  391. LEFT JOIN employee e ON (ct.employee_id = e.id)
  392. LEFT JOIN employee m ON (m.id = e.managerid)
  393. LEFT JOIN pricegroup g ON (ct.pricegroup_id = g.id)
  394. LEFT JOIN language l ON (l.code = ct.language_code)
  395. WHERE $where|;
  396. # redo for invoices, orders and quotations
  397. if ( $form->{l_transnumber}
  398. || $form->{l_invnumber}
  399. || $form->{l_ordnumber}
  400. || $form->{l_quonumber} )
  401. {
  402. my ( $ar, $union, $module );
  403. $query = "";
  404. my $transwhere;
  405. my $openarap = "";
  406. my $openoe = "";
  407. if ( $form->{open} || $form->{closed} ) {
  408. unless ( $form->{open} && $form->{closed} ) {
  409. $openarap = " AND a.amount != a.paid"
  410. if $form->{open};
  411. $openarap = " AND a.amount = a.paid"
  412. if $form->{closed};
  413. $openoe = " AND o.closed = '0'"
  414. if $form->{open};
  415. $openoe = " AND o.closed = '1'"
  416. if $form->{closed};
  417. }
  418. }
  419. if ( $form->{l_transnumber} ) {
  420. $ar = ( $form->{db} eq 'customer' ) ? 'ar' : 'ap';
  421. $module = $ar;
  422. $transwhere = "";
  423. $transwhere .=
  424. " AND a.transdate >= " . $dbh->quote( $form->{transdatefrom} )
  425. if $form->{transdatefrom};
  426. $transwhere .=
  427. " AND a.transdate <= " . $dbh->quote( $form->{transdateto} )
  428. if $form->{transdateto};
  429. $query = qq|
  430. SELECT ct.*, b.description AS business,
  431. a.invnumber, a.ordnumber,
  432. a.quonumber,
  433. a.id AS invid, '$ar' AS module,
  434. 'invoice' AS formtype,
  435. (a.amount = a.paid) AS closed,
  436. a.amount,
  437. a.netamount, e.name AS employee,
  438. m.name AS manager
  439. FROM $form->{db} ct
  440. JOIN $ar a ON (a.$form->{db}_id = ct.id)
  441. LEFT JOIN business b ON (ct.business_id = b.id)
  442. LEFT JOIN employee e ON (a.employee_id = e.id)
  443. LEFT JOIN employee m ON (m.id = e.managerid)
  444. WHERE $where
  445. AND a.invoice = '0'
  446. $transwhere
  447. $openarap |;
  448. $union = qq| UNION |;
  449. }
  450. if ( $form->{l_invnumber} ) {
  451. $ar = ( $form->{db} eq 'customer' ) ? 'ar' : 'ap';
  452. $module = ( $ar eq 'ar' ) ? 'is' : 'ir';
  453. $transwhere = "";
  454. $transwhere .=
  455. " AND a.transdate >= " . $dbh->quote( $form->{transdatefrom} )
  456. if $form->{transdatefrom};
  457. $transwhere .=
  458. " AND a.transdate <= " . $dbh->quote( $form->{transdateto} )
  459. if $form->{transdateto};
  460. $query .= qq|
  461. $union
  462. SELECT ct.*, b.description AS business,
  463. a.invnumber, a.ordnumber, a.quonumber,
  464. a.id AS invid,
  465. '$module' AS module,
  466. 'invoice' AS formtype,
  467. (a.amount = a.paid) AS closed,
  468. a.amount, a.netamount,
  469. e.name AS employee, m.name AS manager
  470. FROM $form->{db} ct
  471. JOIN $ar a ON (a.$form->{db}_id = ct.id)
  472. LEFT JOIN business b ON (ct.business_id = b.id)
  473. LEFT JOIN employee e ON (a.employee_id = e.id)
  474. LEFT JOIN employee m ON (m.id = e.managerid)
  475. WHERE $where
  476. AND a.invoice = '1'
  477. $transwhere
  478. $openarap |;
  479. $union = qq| UNION|;
  480. }
  481. if ( $form->{l_ordnumber} ) {
  482. $transwhere = "";
  483. $transwhere .=
  484. " AND o.transdate >= " . $dbh->quote( $form->{transdatefrom} )
  485. if $form->{transdatefrom};
  486. $transwhere .=
  487. " AND o.transdate <= " . $dbh->quote( $form->{transdateto} )
  488. if $form->{transdateto};
  489. $query .= qq|
  490. $union
  491. SELECT ct.*, b.description AS business,
  492. ' ' AS invnumber, o.ordnumber,
  493. o.quonumber, o.id AS invid,
  494. 'oe' AS module, 'order' AS formtype,
  495. o.closed, o.amount, o.netamount,
  496. e.name AS employee, m.name AS manager
  497. FROM $form->{db} ct
  498. JOIN oe o ON (o.$form->{db}_id = ct.id)
  499. LEFT JOIN business b ON (ct.business_id = b.id)
  500. LEFT JOIN employee e ON (o.employee_id = e.id)
  501. LEFT JOIN employee m ON (m.id = e.managerid)
  502. WHERE $where
  503. AND o.quotation = '0'
  504. $transwhere
  505. $openoe |;
  506. $union = qq| UNION|;
  507. }
  508. if ( $form->{l_quonumber} ) {
  509. $transwhere = "";
  510. $transwhere .=
  511. " AND o.transdate >= " . $dbh->quote( $form->{transdatefrom} )
  512. if $form->{transdatefrom};
  513. $transwhere .=
  514. " AND o.transdate <= " . $dbh->quote( $form->{transdateto} )
  515. if $form->{transdateto};
  516. $query .= qq|
  517. $union
  518. SELECT ct.*, b.description AS business,
  519. ' ' AS invnumber, o.ordnumber,
  520. o.quonumber, o.id AS invid,
  521. 'oe' AS module,
  522. 'quotation' AS formtype,
  523. o.closed, o.amount, o.netamount,
  524. e.name AS employee, m.name AS manager
  525. FROM $form->{db} ct
  526. JOIN oe o ON (o.$form->{db}_id = ct.id)
  527. LEFT JOIN business b ON (ct.business_id = b.id)
  528. LEFT JOIN employee e ON (o.employee_id = e.id)
  529. LEFT JOIN employee m ON (m.id = e.managerid)
  530. WHERE $where
  531. AND o.quotation = '1'
  532. $transwhere
  533. $openoe |;
  534. }
  535. $sortorder .= ", invid";
  536. }
  537. $query .= qq| ORDER BY $sortorder|;
  538. my $sth = $dbh->prepare($query);
  539. $sth->execute || $form->dberror($query);
  540. # accounts
  541. $query = qq|
  542. SELECT c.accno
  543. FROM chart c
  544. JOIN $form->{db}tax t ON (t.chart_id = c.id)
  545. WHERE t.$form->{db}_id = ?|;
  546. my $tth = $dbh->prepare($query);
  547. while ( my $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  548. $tth->execute( $ref->{id} );
  549. while ( ($item) = $tth->fetchrow_array ) {
  550. $ref->{taxaccount} .= "$item ";
  551. }
  552. $tth->finish;
  553. chop $ref->{taxaccount};
  554. $ref->{address} = "";
  555. for (qw(address1 address2 city state zipcode country)) {
  556. $ref->{address} .= "$ref->{$_} ";
  557. }
  558. push @{ $form->{CT} }, $ref;
  559. }
  560. $sth->finish;
  561. $dbh->commit;
  562. }
  563. sub get_history {
  564. my ( $self, $myconfig, $form ) = @_;
  565. # connect to database
  566. my $dbh = $form->{dbh};
  567. my $query;
  568. my $where = "1 = 1";
  569. $form->{sort} = "partnumber" unless $form->{sort};
  570. my $sortorder = $form->{sort};
  571. my %ordinal = ();
  572. my $var;
  573. my $table;
  574. # setup ASC or DESC
  575. $form->sort_order();
  576. if ( $form->{"$form->{db}number"} ne "" ) {
  577. $var = $dbh->quote( $form->like( lc $form->{"$form->{db}number"} ) );
  578. $where .= " AND lower(ct.$form->{db}number) LIKE $var";
  579. }
  580. if ( $form->{address} ne "" ) {
  581. $var = $dbh->quote( $form->like( lc $form->{address} ) );
  582. $where .= " AND lower(ct.address1) ILIKE $var";
  583. }
  584. for (qw(name contact email phone notes city state zipcode country)) {
  585. if ( $form->{$_} ne "" ) {
  586. $var = $dbh->quote( $form->like( lc $form->{$_} ) );
  587. $where .= " AND lower(ct.$_) LIKE $var";
  588. }
  589. }
  590. if ( $form->{employee} ne "" ) {
  591. $var = $dbh->quote($form->like(lc $form->{employee}));
  592. $where .= " AND lower(e.name) LIKE $var";
  593. }
  594. $transwhere .=
  595. " AND a.transdate >= " . $dbh->quote( $form->{transdatefrom} )
  596. if $form->{transdatefrom};
  597. $transwhere .= " AND a.transdate <= " . $dbh->quote( $form->{transdateto} )
  598. if $form->{transdateto};
  599. if ( $form->{open} || $form->{closed} ) {
  600. unless ( $form->{open} && $form->{closed} ) {
  601. if ( $form->{type} eq 'invoice' ) {
  602. $where .= " AND a.amount != a.paid"
  603. if $form->{open};
  604. $where .= " AND a.amount = a.paid"
  605. if $form->{closed};
  606. }
  607. else {
  608. $where .= " AND a.closed = '0'"
  609. if $form->{open};
  610. $where .= " AND a.closed = '1'"
  611. if $form->{closed};
  612. }
  613. }
  614. }
  615. my $invnumber = 'invnumber';
  616. my $deldate = 'deliverydate';
  617. my $buysell;
  618. my $sellprice = "sellprice";
  619. if ( $form->{db} eq 'customer' ) {
  620. $buysell = "buy";
  621. if ( $form->{type} eq 'invoice' ) {
  622. $where .= qq|
  623. AND a.invoice = '1' AND i.assemblyitem = '0'|;
  624. $table = 'ar';
  625. $sellprice = "fxsellprice";
  626. }
  627. else {
  628. $table = 'oe';
  629. if ( $form->{type} eq 'order' ) {
  630. $invnumber = 'ordnumber';
  631. $where .= qq| AND a.quotation = '0'|;
  632. }
  633. else {
  634. $invnumber = 'quonumber';
  635. $where .= qq| AND a.quotation = '1'|;
  636. }
  637. $deldate = 'reqdate';
  638. }
  639. }
  640. if ( $form->{db} eq 'vendor' ) {
  641. $buysell = "sell";
  642. if ( $form->{type} eq 'invoice' ) {
  643. $where .= qq| AND a.invoice = '1' AND i.assemblyitem = '0'|;
  644. $table = 'ap';
  645. $sellprice = "fxsellprice";
  646. }
  647. else {
  648. $table = 'oe';
  649. if ( $form->{type} eq 'order' ) {
  650. $invnumber = 'ordnumber';
  651. $where .= qq| AND a.quotation = '0'|;
  652. }
  653. else {
  654. $invnumber = 'quonumber';
  655. $where .= qq| AND a.quotation = '1'|;
  656. }
  657. $deldate = 'reqdate';
  658. }
  659. }
  660. my $invjoin = qq| JOIN invoice i ON (i.trans_id = a.id)|;
  661. if ( $form->{type} eq 'order' ) {
  662. $invjoin = qq| JOIN orderitems i ON (i.trans_id = a.id)|;
  663. }
  664. if ( $form->{type} eq 'quotation' ) {
  665. $invjoin = qq| JOIN orderitems i ON (i.trans_id = a.id)|;
  666. $where .= qq| AND a.quotation = '1'|;
  667. }
  668. %ordinal = (
  669. partnumber => 9,
  670. description => 12,
  671. "$deldate" => 16,
  672. serialnumber => 17,
  673. projectnumber => 18
  674. );
  675. $sortorder =
  676. "2 $form->{direction}, 1, 11, $ordinal{$sortorder} $form->{direction}";
  677. $query = qq|
  678. SELECT ct.id AS ctid, ct.name, ct.address1,
  679. ct.address2, ct.city, ct.state,
  680. p.id AS pid, p.partnumber, a.id AS invid,
  681. a.$invnumber, a.curr, i.description,
  682. i.qty, i.$sellprice AS sellprice, i.discount,
  683. i.$deldate, i.serialnumber, pr.projectnumber,
  684. e.name AS employee, ct.zipcode, ct.country, i.unit,
  685. (SELECT $buysell
  686. FROM exchangerate ex
  687. WHERE a.curr = ex.curr
  688. AND a.transdate = ex.transdate) AS exchangerate
  689. FROM $form->{db} ct
  690. JOIN $table a ON (a.$form->{db}_id = ct.id)
  691. $invjoin
  692. JOIN parts p ON (p.id = i.parts_id)
  693. LEFT JOIN project pr ON (pr.id = i.project_id)
  694. LEFT JOIN employee e ON (e.id = a.employee_id)
  695. WHERE $where
  696. ORDER BY $sortorder|;
  697. my $sth = $dbh->prepare($query);
  698. $sth->execute || $form->dberror($query);
  699. while ( my $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  700. $ref->{address} = "";
  701. $ref->{exchangerate} ||= 1;
  702. for (qw(address1 address2 city state zipcode country)) {
  703. $ref->{address} .= "$ref->{$_} ";
  704. }
  705. $ref->{id} = $ref->{ctid};
  706. push @{ $form->{CT} }, $ref;
  707. }
  708. $sth->finish;
  709. $dbh->commit;
  710. }
  711. sub pricelist {
  712. my ( $self, $myconfig, $form ) = @_;
  713. # connect to database
  714. my $dbh = $form->{dbh};
  715. my $query;
  716. if ( $form->{db} eq 'customer' ) {
  717. $query = qq|SELECT p.id, p.partnumber, p.description,
  718. p.sellprice, pg.partsgroup, p.partsgroup_id,
  719. m.pricebreak, m.sellprice,
  720. m.validfrom, m.validto, m.curr
  721. FROM partscustomer m
  722. JOIN parts p ON (p.id = m.parts_id)
  723. LEFT JOIN partsgroup pg ON (pg.id = p.partsgroup_id)
  724. WHERE m.customer_id = ?
  725. ORDER BY partnumber|;
  726. }
  727. if ( $form->{db} eq 'vendor' ) {
  728. $query = qq|SELECT p.id, p.partnumber AS sku, p.description,
  729. pg.partsgroup, p.partsgroup_id,
  730. m.partnumber, m.leadtime, m.lastcost, m.curr
  731. FROM partsvendor m
  732. JOIN parts p ON (p.id = m.parts_id)
  733. LEFT JOIN partsgroup pg ON (pg.id = p.partsgroup_id)
  734. WHERE m.vendor_id = ?
  735. ORDER BY p.partnumber|;
  736. }
  737. my $sth;
  738. my $ref;
  739. if ( $form->{id} ) {
  740. $sth = $dbh->prepare($query);
  741. $sth->execute( $form->{id} ) || $form->dberror($query);
  742. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  743. push @{ $form->{all_partspricelist} }, $ref;
  744. }
  745. $sth->finish;
  746. }
  747. $query = qq|SELECT value FROM defaults where setting_key = 'curr'|;
  748. ( $form->{currencies} ) = $dbh->selectrow_array($query);
  749. $query = qq|SELECT id, partsgroup
  750. FROM partsgroup
  751. ORDER BY partsgroup|;
  752. $sth = $dbh->prepare($query);
  753. $sth->execute || $self->dberror($query);
  754. $form->{all_partsgroup} = ();
  755. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  756. push @{ $form->{all_partsgroup} }, $ref;
  757. }
  758. $sth->finish;
  759. $dbh->commit;
  760. }
  761. sub save_pricelist {
  762. my ( $self, $myconfig, $form ) = @_;
  763. my $dbh = $form->{dbh};
  764. my $query = qq|
  765. DELETE FROM parts$form->{db}
  766. WHERE $form->{db}_id = ?}|;
  767. $sth = $dbh->prepare($query);
  768. $sth->execute( $form->{id} ) || $form->dberror($query);
  769. foreach $i ( 1 .. $form->{rowcount} ) {
  770. if ( $form->{"id_$i"} ) {
  771. if ( $form->{db} eq 'customer' ) {
  772. for (qw(pricebreak sellprice)) {
  773. $form->{"${_}_$i"} =
  774. $form->parse_amount( $myconfig, $form->{"${_}_$i"} );
  775. }
  776. $query = qq|
  777. INSERT INTO parts$form->{db}
  778. (parts_id, customer_id,
  779. pricebreak, sellprice,
  780. validfrom, validto, curr)
  781. VALUES (?, ?, ?, ?, ?, ?, ?)|;
  782. @queryargs = (
  783. $form->{"id_$i"}, $form->{id},
  784. $form->{"pricebreak_$i"}, $form->{"sellprice_$i"},
  785. $form->{"validfrom_$i"}, $form->{"validto_$i"},
  786. $form->{"curr_$i"}
  787. );
  788. }
  789. else {
  790. for (qw(leadtime lastcost)) {
  791. $form->{"${_}_$i"} =
  792. $form->parse_amount( $myconfig, $form->{"${_}_$i"} );
  793. }
  794. $query = qq|
  795. INSERT INTO parts$form->{db}
  796. (parts_id, vendor_id,
  797. partnumber, lastcost,
  798. leadtime, curr)
  799. VALUES (?, ?, ?, ?, ?, ?)|;
  800. @queryargs = (
  801. $form->{"id_$i"}, $form->{id},
  802. $form->{"partnumber_$i"}, $form->{"lastcost_$i"},
  803. $form->{"leadtime_$i"}, $form->{"curr_$i"}
  804. );
  805. }
  806. $sth = $dbh->prepare($query);
  807. $sth->execute(@queryargs) || $form->dberror($query);
  808. }
  809. }
  810. $_ = $dbh->commit;
  811. }
  812. sub retrieve_item {
  813. my ( $self, $myconfig, $form ) = @_;
  814. # connect to database
  815. my $dbh = $form->{dbh};
  816. my $i = $form->{rowcount};
  817. my $var;
  818. my $null;
  819. my $where = "WHERE p.obsolete = '0'";
  820. if ( $form->{db} eq 'vendor' ) {
  821. # parts, services, labor
  822. $where .= " AND p.assembly = '0'";
  823. }
  824. if ( $form->{db} eq 'customer' ) {
  825. # parts, assemblies, services
  826. $where .= " AND p.income_accno_id > 0";
  827. }
  828. if ( $form->{"partnumber_$i"} ne "" ) {
  829. $var = $dbh->quote( $form->like( lc $form->{"partnumber_$i"} ) );
  830. $where .= " AND lower(p.partnumber) LIKE $var";
  831. }
  832. if ( $form->{"description_$i"} ne "" ) {
  833. $var = $dbh->quote( $form->like( lc $form->{"description_$i"} ) );
  834. $where .= " AND lower(p.description) LIKE $var";
  835. }
  836. if ( $form->{"partsgroup_$i"} ne "" ) {
  837. ( $null, $var ) = split /--/, $form->{"partsgroup_$i"};
  838. $var = $dbh->quote($var);
  839. $where .= qq| AND p.partsgroup_id = $var|;
  840. }
  841. my $query = qq|
  842. SELECT p.id, p.partnumber, p.description, p.sellprice,
  843. p.lastcost, p.unit, pg.partsgroup, p.partsgroup_id
  844. FROM parts p
  845. LEFT JOIN partsgroup pg ON (pg.id = p.partsgroup_id)
  846. $where
  847. ORDER BY partnumber|;
  848. my $sth = $dbh->prepare($query);
  849. $sth->execute || $form->dberror($query);
  850. my $ref;
  851. $form->{item_list} = ();
  852. while ( $ref = $sth->fetchrow_hashref(NAME_lc) ) {
  853. push @{ $form->{item_list} }, $ref;
  854. }
  855. $sth->finish;
  856. $dbh->commit;
  857. }
  858. 1;