summaryrefslogtreecommitdiff
path: root/LedgerSMB/RP.pm
blob: fc1e48302df4549e651a02ded1533b52e472ee3a (plain)
  1. #=====================================================================
  2. # LedgerSMB
  3. # Small Medium Business Accounting software
  4. #
  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) 2001
  17. #
  18. # Author: DWS Systems Inc.
  19. # Web: http://www.sql-ledger.org
  20. #
  21. # Contributors:
  22. #
  23. #======================================================================
  24. #
  25. # This file has NOT undergone whitespace cleanup.
  26. #
  27. #======================================================================
  28. #
  29. # backend code for reports
  30. #
  31. #======================================================================
  32. package RP;
  33. sub inventory_activity {
  34. my ($self, $myconfig, $form) = @_;
  35. ($form->{fromdate}, $form->{todate}) = $form->from_to($form->{fromyear}, $form->{frommonth}, $form->{interval}) if $form->{fromyear} && $form->{frommonth};
  36. unless ($form->{sort_col}){
  37. $form->{sort_col} = 'partnumber';
  38. }
  39. my $dbh = $form->dbconnect($myconfig) || $form->dberror();
  40. my $where = '';
  41. if ($form->{fromdate}){
  42. $where .= "AND coalesce(ar.duedate, ap.duedate) >= ".$dbh->quote($form->{fromdate});
  43. }
  44. if ($form->{todate}){
  45. $where .= "AND coalesce(ar.duedate, ap.duedate) < ".$dbh->quote($form->{todate}). " ";
  46. }
  47. if ($form->{partnumber}){
  48. $where .= qq|AND p.partnumber ILIKE '%|.$form->{partnumber}.qq|%' |;
  49. }
  50. if ($form->{description}){
  51. $where .= q|AND p.description ILIKE '%|.$form->{description}.q|%' |;
  52. }
  53. $where =~ s/^AND/WHERE/;
  54. my $query = qq|
  55. SELECT min(p.description) AS description,
  56. min(p.partnumber) AS partnumber, sum(
  57. CASE WHEN i.qty > 0 THEN i.qty ELSE 0 END
  58. ) AS sold, sum (
  59. CASE WHEN i.qty > 0 THEN i.sellprice * i.qty ELSE 0 END
  60. ) AS revenue, sum(
  61. CASE WHEN i.qty < 0 THEN i.qty * -1 ELSE 0 END
  62. ) AS received, sum(
  63. CASE WHEN i.qty < 0 THEN i.sellprice * i.qty * -1
  64. ELSE 0 END
  65. ) as expenses, min(p.id) as id
  66. FROM invoice i
  67. INNER JOIN parts p ON (i.parts_id = p.id)
  68. LEFT JOIN ar ON (ar.id = i.trans_id)
  69. LEFT JOIN ap ON (ap.id = i.trans_id)
  70. $where
  71. GROUP BY i.parts_id
  72. ORDER BY $form->{sort_col}
  73. |;
  74. my $sth = $dbh->prepare($query) || $form->dberror($query);
  75. $sth->execute() || $form->dberror($query);
  76. @cols = qw(description sold revenue partnumber received expense);
  77. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  78. $ref->{net_income} = $ref->{revenue} - $ref->{expense};
  79. map {$ref->{$_} =~ s/^\s*//} @cols;
  80. map {$ref->{$_} =~ s/\s*$//} @cols;
  81. push @{$form->{TB}}, $ref;
  82. }
  83. $sth->finish;
  84. $dbh->disconnect;
  85. }
  86. sub yearend_statement {
  87. my ($self, $myconfig, $form) = @_;
  88. # connect to database
  89. my $dbh = $form->dbconnect($myconfig);
  90. # if todate < existing yearends, delete GL and yearends
  91. my $query = qq|SELECT trans_id FROM yearend
  92. WHERE transdate >= '$form->{todate}'|;
  93. my $sth = $dbh->prepare($query);
  94. $sth->execute || $form->dberror($query);
  95. my @trans_id = ();
  96. my $id;
  97. while (($id) = $sth->fetchrow_array) {
  98. push @trans_id, $id;
  99. }
  100. $sth->finish;
  101. $query = qq|DELETE FROM gl
  102. WHERE id = ?|;
  103. $sth = $dbh->prepare($query) || $form->dberror($query);
  104. $query = qq|DELETE FROM acc_trans
  105. WHERE trans_id = ?|;
  106. my $ath = $dbh->prepare($query) || $form->dberror($query);
  107. foreach $id (@trans_id) {
  108. $sth->execute($id);
  109. $ath->execute($id);
  110. $sth->finish;
  111. $ath->finish;
  112. }
  113. my $last_period = 0;
  114. my @categories = qw(I E);
  115. my $category;
  116. $form->{decimalplaces} *= 1;
  117. &get_accounts($dbh, 0, $form->{fromdate}, $form->{todate}, $form, \@categories);
  118. # disconnect
  119. $dbh->disconnect;
  120. # now we got $form->{I}{accno}{ }
  121. # and $form->{E}{accno}{ }
  122. my %account = ( 'I' => { 'label' => 'income',
  123. 'labels' => 'income',
  124. 'ml' => 1 },
  125. 'E' => { 'label' => 'expense',
  126. 'labels' => 'expenses',
  127. 'ml' => -1 }
  128. );
  129. foreach $category (@categories) {
  130. foreach $key (sort keys %{ $form->{$category} }) {
  131. if ($form->{$category}{$key}{charttype} eq 'A') {
  132. $form->{"total_$account{$category}{labels}_this_period"} += $form->{$category}{$key}{this} * $account{$category}{ml};
  133. }
  134. }
  135. }
  136. # totals for income and expenses
  137. $form->{total_income_this_period} = $form->round_amount($form->{total_income_this_period}, $form->{decimalplaces});
  138. $form->{total_expenses_this_period} = $form->round_amount($form->{total_expenses_this_period}, $form->{decimalplaces});
  139. # total for income/loss
  140. $form->{total_this_period} = $form->{total_income_this_period} - $form->{total_expenses_this_period};
  141. }
  142. sub income_statement {
  143. my ($self, $myconfig, $form) = @_;
  144. # connect to database
  145. my $dbh = $form->dbconnect($myconfig);
  146. my $last_period = 0;
  147. my @categories = qw(I E);
  148. my $category;
  149. $form->{decimalplaces} *= 1;
  150. if (! ($form->{fromdate} || $form->{todate})) {
  151. if ($form->{fromyear} && $form->{frommonth}) {
  152. ($form->{fromdate}, $form->{todate}) = $form->from_to($form->{fromyear}, $form->{frommonth}, $form->{interval});
  153. }
  154. }
  155. &get_accounts($dbh, $last_period, $form->{fromdate}, $form->{todate}, $form, \@categories, 1);
  156. if (! ($form->{comparefromdate} || $form->{comparetodate})) {
  157. if ($form->{compareyear} && $form->{comparemonth}) {
  158. ($form->{comparefromdate}, $form->{comparetodate}) = $form->from_to($form->{compareyear}, $form->{comparemonth}, $form->{interval});
  159. }
  160. }
  161. # if there are any compare dates
  162. if ($form->{comparefromdate} || $form->{comparetodate}) {
  163. $last_period = 1;
  164. &get_accounts($dbh, $last_period, $form->{comparefromdate}, $form->{comparetodate}, $form, \@categories, 1);
  165. }
  166. # disconnect
  167. $dbh->disconnect;
  168. # now we got $form->{I}{accno}{ }
  169. # and $form->{E}{accno}{ }
  170. my %account = ( 'I' => { 'label' => 'income',
  171. 'labels' => 'income',
  172. 'ml' => 1 },
  173. 'E' => { 'label' => 'expense',
  174. 'labels' => 'expenses',
  175. 'ml' => -1 }
  176. );
  177. my $str;
  178. foreach $category (@categories) {
  179. foreach $key (sort keys %{ $form->{$category} }) {
  180. # push description onto array
  181. $str = ($form->{l_heading}) ? $form->{padding} : "";
  182. if ($form->{$category}{$key}{charttype} eq "A") {
  183. $str .= ($form->{l_accno}) ? "$form->{$category}{$key}{accno} - $form->{$category}{$key}{description}" : "$form->{$category}{$key}{description}";
  184. }
  185. if ($form->{$category}{$key}{charttype} eq "H") {
  186. if ($account{$category}{subtotal} && $form->{l_subtotal}) {
  187. $dash = "- ";
  188. push(@{$form->{"$account{$category}{label}_account"}}, "$str$form->{bold}$account{$category}{subdescription}$form->{endbold}");
  189. push(@{$form->{"$account{$category}{labels}_this_period"}}, $form->format_amount($myconfig, $account{$category}{subthis} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  190. if ($last_period) {
  191. push(@{$form->{"$account{$category}{labels}_last_period"}}, $form->format_amount($myconfig, $account{$category}{sublast} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  192. }
  193. }
  194. $str = "$form->{br}$form->{bold}$form->{$category}{$key}{description}$form->{endbold}";
  195. $account{$category}{subthis} = $form->{$category}{$key}{this};
  196. $account{$category}{sublast} = $form->{$category}{$key}{last};
  197. $account{$category}{subdescription} = $form->{$category}{$key}{description};
  198. $account{$category}{subtotal} = 1;
  199. $form->{$category}{$key}{this} = 0;
  200. $form->{$category}{$key}{last} = 0;
  201. next unless $form->{l_heading};
  202. $dash = " ";
  203. }
  204. push(@{$form->{"$account{$category}{label}_account"}}, $str);
  205. if ($form->{$category}{$key}{charttype} eq 'A') {
  206. $form->{"total_$account{$category}{labels}_this_period"} += $form->{$category}{$key}{this} * $account{$category}{ml};
  207. $dash = "- ";
  208. }
  209. push(@{$form->{"$account{$category}{labels}_this_period"}}, $form->format_amount($myconfig, $form->{$category}{$key}{this} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  210. # add amount or - for last period
  211. if ($last_period) {
  212. $form->{"total_$account{$category}{labels}_last_period"} += $form->{$category}{$key}{last} * $account{$category}{ml};
  213. push(@{$form->{"$account{$category}{labels}_last_period"}}, $form->format_amount($myconfig,$form->{$category}{$key}{last} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  214. }
  215. }
  216. $str = ($form->{l_heading}) ? $form->{padding} : "";
  217. if ($account{$category}{subtotal} && $form->{l_subtotal}) {
  218. push(@{$form->{"$account{$category}{label}_account"}}, "$str$form->{bold}$account{$category}{subdescription}$form->{endbold}");
  219. push(@{$form->{"$account{$category}{labels}_this_period"}}, $form->format_amount($myconfig, $account{$category}{subthis} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  220. if ($last_period) {
  221. push(@{$form->{"$account{$category}{labels}_last_period"}}, $form->format_amount($myconfig, $account{$category}{sublast} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  222. }
  223. }
  224. }
  225. # totals for income and expenses
  226. $form->{total_income_this_period} = $form->round_amount($form->{total_income_this_period}, $form->{decimalplaces});
  227. $form->{total_expenses_this_period} = $form->round_amount($form->{total_expenses_this_period}, $form->{decimalplaces});
  228. # total for income/loss
  229. $form->{total_this_period} = $form->{total_income_this_period} - $form->{total_expenses_this_period};
  230. if ($last_period) {
  231. # total for income/loss
  232. $form->{total_last_period} = $form->format_amount($myconfig, $form->{total_income_last_period} - $form->{total_expenses_last_period}, $form->{decimalplaces}, "- ");
  233. # totals for income and expenses for last_period
  234. $form->{total_income_last_period} = $form->format_amount($myconfig, $form->{total_income_last_period}, $form->{decimalplaces}, "- ");
  235. $form->{total_expenses_last_period} = $form->format_amount($myconfig, $form->{total_expenses_last_period}, $form->{decimalplaces}, "- ");
  236. }
  237. $form->{total_income_this_period} = $form->format_amount($myconfig,$form->{total_income_this_period}, $form->{decimalplaces}, "- ");
  238. $form->{total_expenses_this_period} = $form->format_amount($myconfig,$form->{total_expenses_this_period}, $form->{decimalplaces}, "- ");
  239. $form->{total_this_period} = $form->format_amount($myconfig,$form->{total_this_period}, $form->{decimalplaces}, "- ");
  240. }
  241. sub balance_sheet {
  242. my ($self, $myconfig, $form) = @_;
  243. # connect to database
  244. my $dbh = $form->dbconnect($myconfig);
  245. my $last_period = 0;
  246. my @categories = qw(A L Q);
  247. my $null;
  248. if ($form->{asofdate}) {
  249. if ($form->{asofyear} && $form->{asofmonth}) {
  250. if ($form->{asofdate} !~ /\W/) {
  251. $form->{asofdate} = "$form->{asofyear}$form->{asofmonth}$form->{asofdate}";
  252. }
  253. }
  254. } else {
  255. if ($form->{asofyear} && $form->{asofmonth}) {
  256. ($null, $form->{asofdate}) = $form->from_to($form->{asofyear}, $form->{asofmonth});
  257. }
  258. }
  259. # if there are any dates construct a where
  260. if ($form->{asofdate}) {
  261. $form->{this_period} = "$form->{asofdate}";
  262. $form->{period} = "$form->{asofdate}";
  263. }
  264. $form->{decimalplaces} *= 1;
  265. &get_accounts($dbh, $last_period, "", $form->{asofdate}, $form, \@categories, 1);
  266. if ($form->{compareasofdate}) {
  267. if ($form->{compareasofyear} && $form->{compareasofmonth}) {
  268. if ($form->{compareasofdate} !~ /\W/) {
  269. $form->{compareasofdate} = "$form->{compareasofyear}$form->{compareasofmonth}$form->{compareasofdate}";
  270. }
  271. }
  272. } else {
  273. if ($form->{compareasofyear} && $form->{compareasofmonth}) {
  274. ($null, $form->{compareasofdate}) = $form->from_to($form->{compareasofyear}, $form->{compareasofmonth});
  275. }
  276. }
  277. # if there are any compare dates
  278. if ($form->{compareasofdate}) {
  279. $last_period = 1;
  280. &get_accounts($dbh, $last_period, "", $form->{compareasofdate}, $form, \@categories, 1);
  281. $form->{last_period} = "$form->{compareasofdate}";
  282. }
  283. # disconnect
  284. $dbh->disconnect;
  285. # now we got $form->{A}{accno}{ } assets
  286. # and $form->{L}{accno}{ } liabilities
  287. # and $form->{Q}{accno}{ } equity
  288. # build asset accounts
  289. my $str;
  290. my $key;
  291. my %account = ( 'A' => { 'label' => 'asset',
  292. 'labels' => 'assets',
  293. 'ml' => -1 },
  294. 'L' => { 'label' => 'liability',
  295. 'labels' => 'liabilities',
  296. 'ml' => 1 },
  297. 'Q' => { 'label' => 'equity',
  298. 'labels' => 'equity',
  299. 'ml' => 1 }
  300. );
  301. foreach $category (@categories) {
  302. foreach $key (sort keys %{ $form->{$category} }) {
  303. $str = ($form->{l_heading}) ? $form->{padding} : "";
  304. if ($form->{$category}{$key}{charttype} eq "A") {
  305. $str .= ($form->{l_accno}) ? "$form->{$category}{$key}{accno} - $form->{$category}{$key}{description}" : "$form->{$category}{$key}{description}";
  306. }
  307. if ($form->{$category}{$key}{charttype} eq "H") {
  308. if ($account{$category}{subtotal} && $form->{l_subtotal}) {
  309. $dash = "- ";
  310. push(@{$form->{"$account{$category}{label}_account"}}, "$str$form->{bold}$account{$category}{subdescription}$form->{endbold}");
  311. push(@{$form->{"$account{$category}{label}_this_period"}}, $form->format_amount($myconfig, $account{$category}{subthis} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  312. if ($last_period) {
  313. push(@{$form->{"$account{$category}{label}_last_period"}}, $form->format_amount($myconfig, $account{$category}{sublast} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  314. }
  315. }
  316. $str = "$form->{bold}$form->{$category}{$key}{description}$form->{endbold}";
  317. $account{$category}{subthis} = $form->{$category}{$key}{this};
  318. $account{$category}{sublast} = $form->{$category}{$key}{last};
  319. $account{$category}{subdescription} = $form->{$category}{$key}{description};
  320. $account{$category}{subtotal} = 1;
  321. $form->{$category}{$key}{this} = 0;
  322. $form->{$category}{$key}{last} = 0;
  323. next unless $form->{l_heading};
  324. $dash = " ";
  325. }
  326. # push description onto array
  327. push(@{$form->{"$account{$category}{label}_account"}}, $str);
  328. if ($form->{$category}{$key}{charttype} eq 'A') {
  329. $form->{"total_$account{$category}{labels}_this_period"} += $form->{$category}{$key}{this} * $account{$category}{ml};
  330. $dash = "- ";
  331. }
  332. push(@{$form->{"$account{$category}{label}_this_period"}}, $form->format_amount($myconfig, $form->{$category}{$key}{this} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  333. if ($last_period) {
  334. $form->{"total_$account{$category}{labels}_last_period"} += $form->{$category}{$key}{last} * $account{$category}{ml};
  335. push(@{$form->{"$account{$category}{label}_last_period"}}, $form->format_amount($myconfig, $form->{$category}{$key}{last} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  336. }
  337. }
  338. $str = ($form->{l_heading}) ? $form->{padding} : "";
  339. if ($account{$category}{subtotal} && $form->{l_subtotal}) {
  340. push(@{$form->{"$account{$category}{label}_account"}}, "$str$form->{bold}$account{$category}{subdescription}$form->{endbold}");
  341. push(@{$form->{"$account{$category}{label}_this_period"}}, $form->format_amount($myconfig, $account{$category}{subthis} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  342. if ($last_period) {
  343. push(@{$form->{"$account{$category}{label}_last_period"}}, $form->format_amount($myconfig, $account{$category}{sublast} * $account{$category}{ml}, $form->{decimalplaces}, $dash));
  344. }
  345. }
  346. }
  347. # totals for assets, liabilities
  348. $form->{total_assets_this_period} = $form->round_amount($form->{total_assets_this_period}, $form->{decimalplaces});
  349. $form->{total_liabilities_this_period} = $form->round_amount($form->{total_liabilities_this_period}, $form->{decimalplaces});
  350. $form->{total_equity_this_period} = $form->round_amount($form->{total_equity_this_period}, $form->{decimalplaces});
  351. # calculate earnings
  352. $form->{earnings_this_period} = $form->{total_assets_this_period} - $form->{total_liabilities_this_period} - $form->{total_equity_this_period};
  353. push(@{$form->{equity_this_period}}, $form->format_amount($myconfig, $form->{earnings_this_period}, $form->{decimalplaces}, "- "));
  354. $form->{total_equity_this_period} = $form->round_amount($form->{total_equity_this_period} + $form->{earnings_this_period}, $form->{decimalplaces});
  355. # add liability + equity
  356. $form->{total_this_period} = $form->format_amount($myconfig, $form->{total_liabilities_this_period} + $form->{total_equity_this_period}, $form->{decimalplaces}, "- ");
  357. if ($last_period) {
  358. # totals for assets, liabilities
  359. $form->{total_assets_last_period} = $form->round_amount($form->{total_assets_last_period}, $form->{decimalplaces});
  360. $form->{total_liabilities_last_period} = $form->round_amount($form->{total_liabilities_last_period}, $form->{decimalplaces});
  361. $form->{total_equity_last_period} = $form->round_amount($form->{total_equity_last_period}, $form->{decimalplaces});
  362. # calculate retained earnings
  363. $form->{earnings_last_period} = $form->{total_assets_last_period} - $form->{total_liabilities_last_period} - $form->{total_equity_last_period};
  364. push(@{$form->{equity_last_period}}, $form->format_amount($myconfig,$form->{earnings_last_period}, $form->{decimalplaces}, "- "));
  365. $form->{total_equity_last_period} = $form->round_amount($form->{total_equity_last_period} + $form->{earnings_last_period}, $form->{decimalplaces});
  366. # add liability + equity
  367. $form->{total_last_period} = $form->format_amount($myconfig, $form->{total_liabilities_last_period} + $form->{total_equity_last_period}, $form->{decimalplaces}, "- ");
  368. }
  369. $form->{total_liabilities_last_period} = $form->format_amount($myconfig, $form->{total_liabilities_last_period}, $form->{decimalplaces}, "- ") if ($form->{total_liabilities_last_period});
  370. $form->{total_equity_last_period} = $form->format_amount($myconfig, $form->{total_equity_last_period}, $form->{decimalplaces}, "- ") if ($form->{total_equity_last_period});
  371. $form->{total_assets_last_period} = $form->format_amount($myconfig, $form->{total_assets_last_period}, $form->{decimalplaces}, "- ") if ($form->{total_assets_last_period});
  372. $form->{total_assets_this_period} = $form->format_amount($myconfig, $form->{total_assets_this_period}, $form->{decimalplaces}, "- ");
  373. $form->{total_liabilities_this_period} = $form->format_amount($myconfig, $form->{total_liabilities_this_period}, $form->{decimalplaces}, "- ");
  374. $form->{total_equity_this_period} = $form->format_amount($myconfig, $form->{total_equity_this_period}, $form->{decimalplaces}, "- ");
  375. }
  376. sub get_accounts {
  377. my ($dbh, $last_period, $fromdate, $todate, $form, $categories, $excludeyearend) = @_;
  378. my $department_id;
  379. my $project_id;
  380. ($null, $department_id) = split /--/, $form->{department};
  381. ($null, $project_id) = split /--/, $form->{projectnumber};
  382. my $query;
  383. my $dpt_where;
  384. my $dpt_join;
  385. my $project;
  386. my $where = "1 = 1";
  387. my $glwhere = "";
  388. my $subwhere = "";
  389. my $yearendwhere = "1 = 1";
  390. my $item;
  391. my $category = "AND (";
  392. foreach $item (@{ $categories }) {
  393. $category .= qq|c.category = '$item' OR |;
  394. }
  395. $category =~ s/OR $/\)/;
  396. # get headings
  397. $query = qq|SELECT accno, description, category
  398. FROM chart c
  399. WHERE c.charttype = 'H'
  400. $category
  401. ORDER by c.accno|;
  402. if ($form->{accounttype} eq 'gifi')
  403. {
  404. $query = qq|SELECT g.accno, g.description, c.category
  405. FROM gifi g
  406. JOIN chart c ON (c.gifi_accno = g.accno)
  407. WHERE c.charttype = 'H'
  408. $category
  409. ORDER BY g.accno|;
  410. }
  411. $sth = $dbh->prepare($query);
  412. $sth->execute || $form->dberror($query);
  413. my @headingaccounts = ();
  414. while ($ref = $sth->fetchrow_hashref(NAME_lc))
  415. {
  416. $form->{$ref->{category}}{$ref->{accno}}{description} = "$ref->{description}";
  417. $form->{$ref->{category}}{$ref->{accno}}{charttype} = "H";
  418. $form->{$ref->{category}}{$ref->{accno}}{accno} = $ref->{accno};
  419. push @headingaccounts, $ref->{accno};
  420. }
  421. $sth->finish;
  422. if ($form->{method} eq 'cash' && !$todate) {
  423. ($todate) = $dbh->selectrow_array(qq|SELECT current_date FROM defaults|);
  424. }
  425. if ($fromdate) {
  426. if ($form->{method} eq 'cash') {
  427. $subwhere .= " AND transdate >= '$fromdate'";
  428. $glwhere = " AND ac.transdate >= '$fromdate'";
  429. } else {
  430. $where .= " AND ac.transdate >= '$fromdate'";
  431. }
  432. }
  433. if ($todate) {
  434. $where .= " AND ac.transdate <= '$todate'";
  435. $subwhere .= " AND transdate <= '$todate'";
  436. $yearendwhere = "ac.transdate < '$todate'";
  437. }
  438. if ($excludeyearend) {
  439. $ywhere = " AND ac.trans_id NOT IN
  440. (SELECT trans_id FROM yearend)";
  441. if ($todate) {
  442. $ywhere = " AND ac.trans_id NOT IN
  443. (SELECT trans_id FROM yearend
  444. WHERE transdate <= '$todate')";
  445. }
  446. if ($fromdate) {
  447. $ywhere = " AND ac.trans_id NOT IN
  448. (SELECT trans_id FROM yearend
  449. WHERE transdate >= '$fromdate')";
  450. if ($todate) {
  451. $ywhere = " AND ac.trans_id NOT IN
  452. (SELECT trans_id FROM yearend
  453. WHERE transdate >= '$fromdate'
  454. AND transdate <= '$todate')";
  455. }
  456. }
  457. }
  458. if ($department_id) {
  459. $dpt_join = qq|
  460. JOIN department t ON (a.department_id = t.id)
  461. |;
  462. $dpt_where = qq|
  463. AND t.id = $department_id
  464. |;
  465. }
  466. if ($project_id) {
  467. $project = qq|
  468. AND ac.project_id = $project_id
  469. |;
  470. }
  471. if ($form->{accounttype} eq 'gifi') {
  472. if ($form->{method} eq 'cash') {
  473. $query = qq|
  474. SELECT g.accno, sum(ac.amount) AS amount,
  475. g.description, c.category
  476. FROM acc_trans ac
  477. JOIN chart c ON (c.id = ac.chart_id)
  478. JOIN ar a ON (a.id = ac.trans_id)
  479. JOIN gifi g ON (g.accno = c.gifi_accno)
  480. $dpt_join
  481. WHERE $where
  482. $ywhere
  483. $dpt_where
  484. $category
  485. AND ac.trans_id IN
  486. (
  487. SELECT trans_id
  488. FROM acc_trans
  489. JOIN chart ON (chart_id = id)
  490. WHERE link LIKE '%AR_paid%'
  491. $subwhere
  492. )
  493. $project
  494. GROUP BY g.accno, g.description, c.category
  495. UNION ALL
  496. SELECT '' AS accno, SUM(ac.amount) AS amount,
  497. '' AS description, c.category
  498. FROM acc_trans ac
  499. JOIN chart c ON (c.id = ac.chart_id)
  500. JOIN ar a ON (a.id = ac.trans_id)
  501. $dpt_join
  502. WHERE $where
  503. $ywhere
  504. $dpt_where
  505. $category
  506. AND c.gifi_accno = ''
  507. AND ac.trans_id IN
  508. (
  509. SELECT trans_id
  510. FROM acc_trans
  511. JOIN chart ON (chart_id = id)
  512. WHERE link LIKE '%AR_paid%'
  513. $subwhere
  514. )
  515. $project
  516. GROUP BY c.category
  517. UNION ALL
  518. SELECT g.accno, sum(ac.amount) AS amount,
  519. g.description, c.category
  520. FROM acc_trans ac
  521. JOIN chart c ON (c.id = ac.chart_id)
  522. JOIN ap a ON (a.id = ac.trans_id)
  523. JOIN gifi g ON (g.accno = c.gifi_accno)
  524. $dpt_join
  525. WHERE $where
  526. $ywhere
  527. $dpt_where
  528. $category
  529. AND ac.trans_id IN
  530. (
  531. SELECT trans_id
  532. FROM acc_trans
  533. JOIN chart ON (chart_id = id)
  534. WHERE link LIKE '%AP_paid%'
  535. $subwhere
  536. )
  537. $project
  538. GROUP BY g.accno, g.description, c.category
  539. UNION ALL
  540. SELECT '' AS accno, SUM(ac.amount) AS amount,
  541. '' AS description, c.category
  542. FROM acc_trans ac
  543. JOIN chart c ON (c.id = ac.chart_id)
  544. JOIN ap a ON (a.id = ac.trans_id)
  545. $dpt_join
  546. WHERE $where
  547. $ywhere
  548. $dpt_where
  549. $category
  550. AND c.gifi_accno = ''
  551. AND ac.trans_id IN
  552. (
  553. SELECT trans_id
  554. FROM acc_trans
  555. JOIN chart ON (chart_id = id)
  556. WHERE link LIKE '%AP_paid%'
  557. $subwhere
  558. )
  559. $project
  560. GROUP BY c.category
  561. UNION ALL
  562. -- add gl
  563. SELECT g.accno, sum(ac.amount) AS amount,
  564. g.description, c.category
  565. FROM acc_trans ac
  566. JOIN chart c ON (c.id = ac.chart_id)
  567. JOIN gifi g ON (g.accno = c.gifi_accno)
  568. JOIN gl a ON (a.id = ac.trans_id)
  569. $dpt_join
  570. WHERE $where
  571. $ywhere
  572. $glwhere
  573. $dpt_where
  574. $category
  575. AND NOT (c.link = 'AR' OR c.link = 'AP')
  576. $project
  577. GROUP BY g.accno, g.description, c.category
  578. UNION ALL
  579. SELECT '' AS accno, SUM(ac.amount) AS amount,
  580. '' AS description, c.category
  581. FROM acc_trans ac
  582. JOIN chart c ON (c.id = ac.chart_id)
  583. JOIN gl a ON (a.id = ac.trans_id)
  584. $dpt_join
  585. WHERE $where
  586. $ywhere
  587. $glwhere
  588. $dpt_where
  589. $category
  590. AND c.gifi_accno = ''
  591. AND NOT (c.link = 'AR' OR c.link = 'AP')
  592. $project
  593. GROUP BY c.category
  594. |;
  595. if ($excludeyearend) {
  596. # this is for the yearend
  597. $query .= qq|
  598. UNION ALL
  599. SELECT g.accno, sum(ac.amount) AS amount,
  600. g.description, c.category
  601. FROM yearend y
  602. JOIN gl a ON (a.id = y.trans_id)
  603. JOIN acc_trans ac ON (ac.trans_id = y.trans_id)
  604. JOIN chart c ON (c.id = ac.chart_id)
  605. JOIN gifi g ON (g.accno = c.gifi_accno)
  606. $dpt_join
  607. WHERE $yearendwhere
  608. AND c.category = 'Q'
  609. $dpt_where
  610. $project
  611. GROUP BY g.accno, g.description, c.category
  612. |;
  613. }
  614. } else {
  615. if ($department_id) {
  616. $dpt_join = qq|
  617. JOIN dpt_trans t ON (t.trans_id = ac.trans_id)
  618. |;
  619. $dpt_where = qq|
  620. AND t.department_id = $department_id
  621. |;
  622. }
  623. $query = qq|
  624. SELECT g.accno, SUM(ac.amount) AS amount,
  625. g.description, c.category
  626. FROM acc_trans ac
  627. JOIN chart c ON (c.id = ac.chart_id)
  628. JOIN gifi g ON (c.gifi_accno = g.accno)
  629. $dpt_join
  630. WHERE $where
  631. $ywhere
  632. $dpt_where
  633. $category
  634. $project
  635. GROUP BY g.accno, g.description, c.category
  636. UNION ALL
  637. SELECT '' AS accno, SUM(ac.amount) AS amount,
  638. '' AS description, c.category
  639. FROM acc_trans ac
  640. JOIN chart c ON (c.id = ac.chart_id)
  641. $dpt_join
  642. WHERE $where
  643. $ywhere
  644. $dpt_where
  645. $category
  646. AND c.gifi_accno = ''
  647. $project
  648. GROUP BY c.category
  649. |;
  650. if ($excludeyearend) {
  651. # this is for the yearend
  652. $query .= qq|
  653. UNION ALL
  654. SELECT g.accno, sum(ac.amount) AS amount,
  655. g.description, c.category
  656. FROM yearend y
  657. JOIN gl a ON (a.id = y.trans_id)
  658. JOIN acc_trans ac ON (ac.trans_id = y.trans_id)
  659. JOIN chart c ON (c.id = ac.chart_id)
  660. JOIN gifi g ON (g.accno = c.gifi_accno)
  661. $dpt_join
  662. WHERE $yearendwhere
  663. AND c.category = 'Q'
  664. $dpt_where
  665. $project
  666. GROUP BY g.accno, g.description, c.category
  667. |;
  668. }
  669. }
  670. } else { # standard account
  671. if ($form->{method} eq 'cash') {
  672. $query = qq|
  673. SELECT c.accno, sum(ac.amount) AS amount,
  674. c.description, c.category
  675. FROM acc_trans ac
  676. JOIN chart c ON (c.id = ac.chart_id)
  677. JOIN ar a ON (a.id = ac.trans_id)
  678. $dpt_join
  679. WHERE $where
  680. $ywhere
  681. $dpt_where
  682. $category
  683. AND ac.trans_id IN
  684. (
  685. SELECT trans_id
  686. FROM acc_trans
  687. JOIN chart ON (chart_id = id)
  688. WHERE link LIKE '%AR_paid%'
  689. $subwhere
  690. )
  691. $project
  692. GROUP BY c.accno, c.description, c.category
  693. UNION ALL
  694. SELECT c.accno, sum(ac.amount) AS amount,
  695. c.description, c.category
  696. FROM acc_trans ac
  697. JOIN chart c ON (c.id = ac.chart_id)
  698. JOIN ap a ON (a.id = ac.trans_id)
  699. $dpt_join
  700. WHERE $where
  701. $ywhere
  702. $dpt_where
  703. $category
  704. AND ac.trans_id IN
  705. (
  706. SELECT trans_id
  707. FROM acc_trans
  708. JOIN chart ON (chart_id = id)
  709. WHERE link LIKE '%AP_paid%'
  710. $subwhere
  711. )
  712. $project
  713. GROUP BY c.accno, c.description, c.category
  714. UNION ALL
  715. SELECT c.accno, sum(ac.amount) AS amount,
  716. c.description, c.category
  717. FROM acc_trans ac
  718. JOIN chart c ON (c.id = ac.chart_id)
  719. JOIN gl a ON (a.id = ac.trans_id)
  720. $dpt_join
  721. WHERE $where
  722. $ywhere
  723. $glwhere
  724. $dpt_where
  725. $category
  726. AND NOT (c.link = 'AR' OR c.link = 'AP')
  727. $project
  728. GROUP BY c.accno, c.description, c.category
  729. |;
  730. if ($excludeyearend) {
  731. # this is for the yearend
  732. $query .= qq|
  733. UNION ALL
  734. SELECT c.accno, sum(ac.amount) AS amount,
  735. c.description, c.category
  736. FROM yearend y
  737. JOIN gl a ON (a.id = y.trans_id)
  738. JOIN acc_trans ac ON (ac.trans_id = y.trans_id)
  739. JOIN chart c ON (c.id = ac.chart_id)
  740. $dpt_join
  741. WHERE $yearendwhere
  742. AND c.category = 'Q'
  743. $dpt_where
  744. $project
  745. GROUP BY c.accno, c.description, c.category
  746. |;
  747. }
  748. } else {
  749. if ($department_id) {
  750. $dpt_join = qq|
  751. JOIN dpt_trans t ON (t.trans_id = ac.trans_id)
  752. |;
  753. $dpt_where = qq|
  754. AND t.department_id = $department_id
  755. |;
  756. }
  757. $query = qq|
  758. SELECT c.accno, sum(ac.amount) AS amount,
  759. c.description, c.category
  760. FROM acc_trans ac
  761. JOIN chart c ON (c.id = ac.chart_id)
  762. $dpt_join
  763. WHERE $where
  764. $ywhere
  765. $dpt_where
  766. $category
  767. $project
  768. GROUP BY c.accno, c.description, c.category
  769. |;
  770. if ($excludeyearend) {
  771. # this is for the yearend
  772. $query .= qq|
  773. UNION ALL
  774. SELECT c.accno, sum(ac.amount) AS amount,
  775. c.description, c.category
  776. FROM yearend y
  777. JOIN gl a ON (a.id = y.trans_id)
  778. JOIN acc_trans ac ON (ac.trans_id = y.trans_id)
  779. JOIN chart c ON (c.id = ac.chart_id)
  780. $dpt_join
  781. WHERE $yearendwhere
  782. AND c.category = 'Q'
  783. $dpt_where
  784. $project
  785. GROUP BY c.accno, c.description, c.category
  786. |;
  787. }
  788. }
  789. }
  790. my @accno;
  791. my $accno;
  792. my $ref;
  793. my $sth = $dbh->prepare($query);
  794. $sth->execute || $form->dberror($query);
  795. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  796. # get last heading account
  797. @accno = grep { $_ le "$ref->{accno}" } @headingaccounts;
  798. $accno = pop @accno;
  799. if ($accno && ($accno ne $ref->{accno}) ) {
  800. if ($last_period)
  801. {
  802. $form->{$ref->{category}}{$accno}{last} += $ref->{amount};
  803. } else {
  804. $form->{$ref->{category}}{$accno}{this} += $ref->{amount};
  805. }
  806. }
  807. $form->{$ref->{category}}{$ref->{accno}}{accno} = $ref->{accno};
  808. $form->{$ref->{category}}{$ref->{accno}}{description} = $ref->{description};
  809. $form->{$ref->{category}}{$ref->{accno}}{charttype} = "A";
  810. if ($last_period) {
  811. $form->{$ref->{category}}{$ref->{accno}}{last} += $ref->{amount};
  812. } else {
  813. $form->{$ref->{category}}{$ref->{accno}}{this} += $ref->{amount};
  814. }
  815. }
  816. $sth->finish;
  817. # remove accounts with zero balance
  818. foreach $category (@{ $categories }) {
  819. foreach $accno (keys %{ $form->{$category} }) {
  820. $form->{$category}{$accno}{last} = $form->round_amount($form->{$category}{$accno}{last}, $form->{decimalplaces});
  821. $form->{$category}{$accno}{this} = $form->round_amount($form->{$category}{$accno}{this}, $form->{decimalplaces});
  822. delete $form->{$category}{$accno} if ($form->{$category}{$accno}{this} == 0 && $form->{$category}{$accno}{last} == 0);
  823. }
  824. }
  825. }
  826. sub trial_balance {
  827. my ($self, $myconfig, $form) = @_;
  828. my $dbh = $form->dbconnect($myconfig);
  829. my ($query, $sth, $ref);
  830. my %balance = ();
  831. my %trb = ();
  832. my $null;
  833. my $department_id;
  834. my $project_id;
  835. my @headingaccounts = ();
  836. my $dpt_where;
  837. my $dpt_join;
  838. my $project;
  839. my $where = "1 = 1";
  840. my $invwhere = $where;
  841. ($null, $department_id) = split /--/, $form->{department};
  842. ($null, $project_id) = split /--/, $form->{projectnumber};
  843. if ($department_id) {
  844. $dpt_join = qq|
  845. JOIN dpt_trans t ON (ac.trans_id = t.trans_id)
  846. |;
  847. $dpt_where = qq|
  848. AND t.department_id = $department_id
  849. |;
  850. }
  851. if ($project_id) {
  852. $project = qq|
  853. AND ac.project_id = $project_id
  854. |;
  855. }
  856. ($form->{fromdate}, $form->{todate}) = $form->from_to($form->{year}, $form->{month}, $form->{interval}) if $form->{year} && $form->{month};
  857. # get beginning balances
  858. if ($form->{fromdate}) {
  859. if ($form->{accounttype} eq 'gifi') {
  860. $query = qq|SELECT g.accno, c.category, SUM(ac.amount) AS amount,
  861. g.description, c.contra
  862. FROM acc_trans ac
  863. JOIN chart c ON (ac.chart_id = c.id)
  864. JOIN gifi g ON (c.gifi_accno = g.accno)
  865. $dpt_join
  866. WHERE ac.transdate < '$form->{fromdate}'
  867. $dpt_where
  868. $project
  869. GROUP BY g.accno, c.category, g.description, c.contra
  870. |;
  871. } else {
  872. $query = qq|SELECT c.accno, c.category, SUM(ac.amount) AS amount,
  873. c.description, c.contra
  874. FROM acc_trans ac
  875. JOIN chart c ON (ac.chart_id = c.id)
  876. $dpt_join
  877. WHERE ac.transdate < '$form->{fromdate}'
  878. $dpt_where
  879. $project
  880. GROUP BY c.accno, c.category, c.description, c.contra
  881. |;
  882. }
  883. $sth = $dbh->prepare($query);
  884. $sth->execute || $form->dberror($query);
  885. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  886. $ref->{amount} = $form->round_amount($ref->{amount}, 2);
  887. $balance{$ref->{accno}} = $ref->{amount};
  888. if ($form->{all_accounts}) {
  889. $trb{$ref->{accno}}{description} = $ref->{description};
  890. $trb{$ref->{accno}}{charttype} = 'A';
  891. $trb{$ref->{accno}}{category} = $ref->{category};
  892. $trb{$ref->{accno}}{contra} = $ref->{contra};
  893. }
  894. }
  895. $sth->finish;
  896. }
  897. # get headings
  898. $query = qq|SELECT c.accno, c.description, c.category
  899. FROM chart c
  900. WHERE c.charttype = 'H'
  901. ORDER by c.accno|;
  902. if ($form->{accounttype} eq 'gifi')
  903. {
  904. $query = qq|SELECT g.accno, g.description, c.category, c.contra
  905. FROM gifi g
  906. JOIN chart c ON (c.gifi_accno = g.accno)
  907. WHERE c.charttype = 'H'
  908. ORDER BY g.accno|;
  909. }
  910. $sth = $dbh->prepare($query);
  911. $sth->execute || $form->dberror($query);
  912. while ($ref = $sth->fetchrow_hashref(NAME_lc))
  913. {
  914. $trb{$ref->{accno}}{description} = $ref->{description};
  915. $trb{$ref->{accno}}{charttype} = 'H';
  916. $trb{$ref->{accno}}{category} = $ref->{category};
  917. $trb{$ref->{accno}}{contra} = $ref->{contra};
  918. push @headingaccounts, $ref->{accno};
  919. }
  920. $sth->finish;
  921. if ($form->{fromdate} || $form->{todate}) {
  922. if ($form->{fromdate}) {
  923. $where .= " AND ac.transdate >= '$form->{fromdate}'";
  924. $invwhere .= " AND a.transdate >= '$form->{fromdate}'";
  925. }
  926. if ($form->{todate}) {
  927. $where .= " AND ac.transdate <= '$form->{todate}'";
  928. $invwhere .= " AND a.transdate <= '$form->{todate}'";
  929. }
  930. }
  931. if ($form->{accounttype} eq 'gifi') {
  932. $query = qq|SELECT g.accno, g.description, c.category,
  933. SUM(ac.amount) AS amount, c.contra
  934. FROM acc_trans ac
  935. JOIN chart c ON (c.id = ac.chart_id)
  936. JOIN gifi g ON (c.gifi_accno = g.accno)
  937. $dpt_join
  938. WHERE $where
  939. $dpt_where
  940. $project
  941. GROUP BY g.accno, g.description, c.category, c.contra
  942. ORDER BY accno|;
  943. } else {
  944. $query = qq|SELECT c.accno, c.description, c.category,
  945. SUM(ac.amount) AS amount, c.contra
  946. FROM acc_trans ac
  947. JOIN chart c ON (c.id = ac.chart_id)
  948. $dpt_join
  949. WHERE $where
  950. $dpt_where
  951. $project
  952. GROUP BY c.accno, c.description, c.category, c.contra
  953. ORDER BY accno|;
  954. }
  955. $sth = $dbh->prepare($query);
  956. $sth->execute || $form->dberror($query);
  957. # prepare query for each account
  958. $query = qq|SELECT (SELECT SUM(ac.amount) * -1
  959. FROM acc_trans ac
  960. JOIN chart c ON (c.id = ac.chart_id)
  961. $dpt_join
  962. WHERE $where
  963. $dpt_where
  964. $project
  965. AND ac.amount < 0
  966. AND c.accno = ?) AS debit,
  967. (SELECT SUM(ac.amount)
  968. FROM acc_trans ac
  969. JOIN chart c ON (c.id = ac.chart_id)
  970. $dpt_join
  971. WHERE $where
  972. $dpt_where
  973. $project
  974. AND ac.amount > 0
  975. AND c.accno = ?) AS credit
  976. |;
  977. if ($form->{accounttype} eq 'gifi') {
  978. $query = qq|SELECT (SELECT SUM(ac.amount) * -1
  979. FROM acc_trans ac
  980. JOIN chart c ON (c.id = ac.chart_id)
  981. $dpt_join
  982. WHERE $where
  983. $dpt_where
  984. $project
  985. AND ac.amount < 0
  986. AND c.gifi_accno = ?) AS debit,
  987. (SELECT SUM(ac.amount)
  988. FROM acc_trans ac
  989. JOIN chart c ON (c.id = ac.chart_id)
  990. $dpt_join
  991. WHERE $where
  992. $dpt_where
  993. $project
  994. AND ac.amount > 0
  995. AND c.gifi_accno = ?) AS credit|;
  996. }
  997. $drcr = $dbh->prepare($query);
  998. # calculate debit and credit for the period
  999. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1000. $trb{$ref->{accno}}{description} = $ref->{description};
  1001. $trb{$ref->{accno}}{charttype} = 'A';
  1002. $trb{$ref->{accno}}{category} = $ref->{category};
  1003. $trb{$ref->{accno}}{contra} = $ref->{contra};
  1004. $trb{$ref->{accno}}{amount} += $ref->{amount};
  1005. }
  1006. $sth->finish;
  1007. my ($debit, $credit);
  1008. foreach my $accno (sort keys %trb) {
  1009. $ref = ();
  1010. $ref->{accno} = $accno;
  1011. for (qw(description category contra charttype amount)) { $ref->{$_} = $trb{$accno}{$_} }
  1012. $ref->{balance} = $balance{$ref->{accno}};
  1013. if ($trb{$accno}{charttype} eq 'A') {
  1014. if ($project_id) {
  1015. if ($ref->{amount} < 0) {
  1016. $ref->{debit} = $ref->{amount} * -1;
  1017. } else {
  1018. $ref->{credit} = $ref->{amount};
  1019. }
  1020. next if $form->round_amount($ref->{amount}, 2) == 0;
  1021. } else {
  1022. # get DR/CR
  1023. $drcr->execute($ref->{accno}, $ref->{accno});
  1024. ($debit, $credit) = (0,0);
  1025. while (($debit, $credit) = $drcr->fetchrow_array) {
  1026. $ref->{debit} += $debit;
  1027. $ref->{credit} += $credit;
  1028. }
  1029. $drcr->finish;
  1030. }
  1031. $ref->{debit} = $form->round_amount($ref->{debit}, 2);
  1032. $ref->{credit} = $form->round_amount($ref->{credit}, 2);
  1033. if (!$form->{all_accounts}) {
  1034. next if $form->round_amount($ref->{debit} + $ref->{credit}, 2) == 0;
  1035. }
  1036. }
  1037. # add subtotal
  1038. @accno = grep { $_ le "$ref->{accno}" } @headingaccounts;
  1039. $accno = pop @accno;
  1040. if ($accno) {
  1041. $trb{$accno}{debit} += $ref->{debit};
  1042. $trb{$accno}{credit} += $ref->{credit};
  1043. }
  1044. push @{ $form->{TB} }, $ref;
  1045. }
  1046. $dbh->disconnect;
  1047. # debits and credits for headings
  1048. foreach $accno (@headingaccounts) {
  1049. foreach $ref (@{ $form->{TB} }) {
  1050. if ($accno eq $ref->{accno}) {
  1051. $ref->{debit} = $trb{$accno}{debit};
  1052. $ref->{credit} = $trb{$accno}{credit};
  1053. }
  1054. }
  1055. }
  1056. }
  1057. sub aging {
  1058. my ($self, $myconfig, $form) = @_;
  1059. # connect to database
  1060. my $dbh = $form->dbconnect($myconfig);
  1061. my $invoice = ($form->{arap} eq 'ar') ? 'is' : 'ir';
  1062. my $query = qq|SELECT curr FROM defaults|;
  1063. ($form->{currencies}) = $dbh->selectrow_array($query);
  1064. ($null, $form->{todate}) = $form->from_to($form->{year}, $form->{month}) if $form->{year} && $form->{month};
  1065. if (! $form->{todate}) {
  1066. $query = qq|SELECT current_date FROM defaults|;
  1067. ($form->{todate}) = $dbh->selectrow_array($query);
  1068. }
  1069. my $where = "1 = 1";
  1070. my $name;
  1071. my $null;
  1072. my $ref;
  1073. my $transdate = ($form->{overdue}) ? "duedate" : "transdate";
  1074. if ($form->{"$form->{ct}_id"}) {
  1075. $where .= qq| AND ct.id = $form->{"$form->{ct}_id"}|;
  1076. } else {
  1077. if ($form->{$form->{ct}} ne "") {
  1078. $name = $form->like(lc $form->{$form->{ct}});
  1079. $where .= qq| AND lower(ct.name) LIKE '$name'| if $form->{$form->{ct}};
  1080. }
  1081. }
  1082. if ($form->{department}) {
  1083. ($null, $department_id) = split /--/, $form->{department};
  1084. $where .= qq| AND a.department_id = $department_id|;
  1085. }
  1086. # select outstanding vendors or customers, depends on $ct
  1087. $query = qq|SELECT DISTINCT ct.id, ct.name, ct.language_code
  1088. FROM $form->{ct} ct
  1089. JOIN $form->{arap} a ON (a.$form->{ct}_id = ct.id)
  1090. WHERE $where
  1091. AND a.paid != a.amount
  1092. AND (a.$transdate <= '$form->{todate}')
  1093. ORDER BY ct.name|;
  1094. my $sth = $dbh->prepare($query);
  1095. $sth->execute || $form->dberror;
  1096. my @ot = ();
  1097. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1098. push @ot, $ref;
  1099. }
  1100. $sth->finish;
  1101. my $buysell = ($form->{arap} eq 'ar') ? 'buy' : 'sell';
  1102. my %interval = ( 'Pg' => {
  1103. 'c0' => "(date '$form->{todate}' - interval '0 days')",
  1104. 'c30' => "(date '$form->{todate}' - interval '30 days')",
  1105. 'c60' => "(date '$form->{todate}' - interval '60 days')",
  1106. 'c90' => "(date '$form->{todate}' - interval '90 days')" },
  1107. 'DB2' => {
  1108. 'c0' => "(date ('$form->{todate}') - 0 days)",
  1109. 'c30' => "(date ('$form->{todate}') - 30 days)",
  1110. 'c60' => "(date ('$form->{todate}') - 60 days)",
  1111. 'c90' => "(date ('$form->{todate}') - 90 days)" }
  1112. );
  1113. $interval{Oracle} = $interval{PgPP} = $interval{Pg};
  1114. # for each company that has some stuff outstanding
  1115. $form->{currencies} ||= ":";
  1116. $where = qq|
  1117. a.paid != a.amount
  1118. AND c.id = ?
  1119. AND a.curr = ?|;
  1120. if ($department_id) {
  1121. $where .= qq| AND a.department_id = $department_id|;
  1122. }
  1123. $query = "";
  1124. my $union = "";
  1125. if ($form->{c0}) {
  1126. $query .= qq|
  1127. SELECT c.id AS ctid, c.$form->{ct}number, c.name,
  1128. c.address1, c.address2, c.city, c.state, c.zipcode, c.country,
  1129. c.contact, c.email,
  1130. c.phone as $form->{ct}phone, c.fax as $form->{ct}fax,
  1131. c.$form->{ct}number, c.taxnumber as $form->{ct}taxnumber,
  1132. a.invnumber, a.transdate, a.till, a.ordnumber, a.ponumber, a.notes,
  1133. (a.amount - a.paid) as c0, 0.00 as c30, 0.00 as c60, 0.00 as c90,
  1134. a.duedate, a.invoice, a.id, a.curr,
  1135. (SELECT $buysell FROM exchangerate e
  1136. WHERE a.curr = e.curr
  1137. AND e.transdate = a.transdate) AS exchangerate
  1138. FROM $form->{arap} a
  1139. JOIN $form->{ct} c ON (a.$form->{ct}_id = c.id)
  1140. WHERE $where
  1141. AND (
  1142. a.$transdate <= $interval{$myconfig->{dbdriver}}{c0}
  1143. AND a.$transdate >= $interval{$myconfig->{dbdriver}}{c30}
  1144. )
  1145. |;
  1146. $union = qq|
  1147. UNION
  1148. |;
  1149. }
  1150. if ($form->{c30}) {
  1151. $query .= qq|
  1152. $union
  1153. SELECT c.id AS ctid, c.$form->{ct}number, c.name,
  1154. c.address1, c.address2, c.city, c.state, c.zipcode, c.country,
  1155. c.contact, c.email,
  1156. c.phone as $form->{ct}phone, c.fax as $form->{ct}fax,
  1157. c.$form->{ct}number, c.taxnumber as $form->{ct}taxnumber,
  1158. a.invnumber, a.transdate, a.till, a.ordnumber, a.ponumber, a.notes,
  1159. 0.00 as c0, (a.amount - a.paid) as c30, 0.00 as c60, 0.00 as c90,
  1160. a.duedate, a.invoice, a.id, a.curr,
  1161. (SELECT $buysell FROM exchangerate e
  1162. WHERE a.curr = e.curr
  1163. AND e.transdate = a.transdate) AS exchangerate
  1164. FROM $form->{arap} a
  1165. JOIN $form->{ct} c ON (a.$form->{ct}_id = c.id)
  1166. WHERE $where
  1167. AND (
  1168. a.$transdate < $interval{$myconfig->{dbdriver}}{c30}
  1169. AND a.$transdate >= $interval{$myconfig->{dbdriver}}{c60}
  1170. )
  1171. |;
  1172. $union = qq|
  1173. UNION
  1174. |;
  1175. }
  1176. if ($form->{c60}) {
  1177. $query .= qq|
  1178. $union
  1179. SELECT c.id AS ctid, c.$form->{ct}number, c.name,
  1180. c.address1, c.address2, c.city, c.state, c.zipcode, c.country,
  1181. c.contact, c.email,
  1182. c.phone as $form->{ct}phone, c.fax as $form->{ct}fax,
  1183. c.$form->{ct}number, c.taxnumber as $form->{ct}taxnumber,
  1184. a.invnumber, a.transdate, a.till, a.ordnumber, a.ponumber, a.notes,
  1185. 0.00 as c0, 0.00 as c30, (a.amount - a.paid) as c60, 0.00 as c90,
  1186. a.duedate, a.invoice, a.id, a.curr,
  1187. (SELECT $buysell FROM exchangerate e
  1188. WHERE a.curr = e.curr
  1189. AND e.transdate = a.transdate) AS exchangerate
  1190. FROM $form->{arap} a
  1191. JOIN $form->{ct} c ON (a.$form->{ct}_id = c.id)
  1192. WHERE $where
  1193. AND (
  1194. a.$transdate < $interval{$myconfig->{dbdriver}}{c60}
  1195. AND a.$transdate >= $interval{$myconfig->{dbdriver}}{c90}
  1196. )
  1197. |;
  1198. $union = qq|
  1199. UNION
  1200. |;
  1201. }
  1202. if ($form->{c90}) {
  1203. $query .= qq|
  1204. $union
  1205. SELECT c.id AS ctid, c.$form->{ct}number, c.name,
  1206. c.address1, c.address2, c.city, c.state, c.zipcode, c.country,
  1207. c.contact, c.email,
  1208. c.phone as $form->{ct}phone, c.fax as $form->{ct}fax,
  1209. c.$form->{ct}number, c.taxnumber as $form->{ct}taxnumber,
  1210. a.invnumber, a.transdate, a.till, a.ordnumber, a.ponumber, a.notes,
  1211. 0.00 as c0, 0.00 as c30, 0.00 as c60, (a.amount - a.paid) as c90,
  1212. a.duedate, a.invoice, a.id, a.curr,
  1213. (SELECT $buysell FROM exchangerate e
  1214. WHERE a.curr = e.curr
  1215. AND e.transdate = a.transdate) AS exchangerate
  1216. FROM $form->{arap} a
  1217. JOIN $form->{ct} c ON (a.$form->{ct}_id = c.id)
  1218. WHERE $where
  1219. AND a.$transdate < $interval{$myconfig->{dbdriver}}{c90}
  1220. |;
  1221. }
  1222. $query .= qq|
  1223. ORDER BY ctid, $transdate, invnumber|;
  1224. $sth = $dbh->prepare($query) || $form->dberror($query);
  1225. my @var = ();
  1226. if ($form->{c0} + $form->{c30} + $form->{c60} + $form->{c90}) {
  1227. foreach $curr (split /:/, $form->{currencies}) {
  1228. foreach $item (@ot) {
  1229. @var = ();
  1230. for (qw(c0 c30 c60 c90)) { push @var, ($item->{id}, $curr) if $form->{$_} }
  1231. $sth->execute(@var);
  1232. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1233. $ref->{module} = ($ref->{invoice}) ? $invoice : $form->{arap};
  1234. $ref->{module} = 'ps' if $ref->{till};
  1235. $ref->{exchangerate} = 1 unless $ref->{exchangerate};
  1236. $ref->{language_code} = $item->{language_code};
  1237. push @{ $form->{AG} }, $ref;
  1238. }
  1239. $sth->finish;
  1240. }
  1241. }
  1242. }
  1243. # get language
  1244. my $query = qq|SELECT *
  1245. FROM language
  1246. ORDER BY 2|;
  1247. $sth = $dbh->prepare($query);
  1248. $sth->execute || $form->dberror($query);
  1249. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  1250. push @{ $form->{all_language} }, $ref;
  1251. }
  1252. $sth->finish;
  1253. # disconnect
  1254. $dbh->disconnect;
  1255. }
  1256. sub get_customer {
  1257. my ($self, $myconfig, $form) = @_;
  1258. # connect to database
  1259. my $dbh = $form->dbconnect($myconfig);
  1260. my $query = qq|SELECT name, email, cc, bcc
  1261. FROM $form->{ct} ct
  1262. WHERE ct.id = $form->{"$form->{ct}_id"}|;
  1263. ($form->{$form->{ct}}, $form->{email}, $form->{cc}, $form->{bcc}) = $dbh->selectrow_array($query);
  1264. $dbh->disconnect;
  1265. }
  1266. sub get_taxaccounts {
  1267. my ($self, $myconfig, $form) = @_;
  1268. # connect to database
  1269. my $dbh = $form->dbconnect($myconfig);
  1270. my $ARAP = uc $form->{db};
  1271. # get tax accounts
  1272. my $query = qq|SELECT DISTINCT c.accno, c.description
  1273. FROM chart c
  1274. JOIN tax t ON (c.id = t.chart_id)
  1275. WHERE c.link LIKE '%${ARAP}_tax%'
  1276. ORDER BY c.accno|;
  1277. my $sth = $dbh->prepare($query);
  1278. $sth->execute || $form->dberror;
  1279. my $ref = ();
  1280. while ($ref = $sth->fetchrow_hashref(NAME_lc) ) {
  1281. push @{ $form->{taxaccounts} }, $ref;
  1282. }
  1283. $sth->finish;
  1284. # get gifi tax accounts
  1285. my $query = qq|SELECT DISTINCT g.accno, g.description
  1286. FROM gifi g
  1287. JOIN chart c ON (c.gifi_accno= g.accno)
  1288. JOIN tax t ON (c.id = t.chart_id)
  1289. WHERE c.link LIKE '%${ARAP}_tax%'
  1290. ORDER BY accno|;
  1291. my $sth = $dbh->prepare($query);
  1292. $sth->execute || $form->dberror;
  1293. while ($ref = $sth->fetchrow_hashref(NAME_lc) ) {
  1294. push @{ $form->{gifi_taxaccounts} }, $ref;
  1295. }
  1296. $sth->finish;
  1297. $dbh->disconnect;
  1298. }
  1299. sub tax_report {
  1300. my ($self, $myconfig, $form) = @_;
  1301. # connect to database
  1302. my $dbh = $form->dbconnect($myconfig);
  1303. my ($null, $department_id) = split /--/, $form->{department};
  1304. # build WHERE
  1305. my $where = "1 = 1";
  1306. my $cashwhere = "";
  1307. if ($department_id) {
  1308. $where .= qq|
  1309. AND a.department_id = $department_id
  1310. |;
  1311. }
  1312. my $query;
  1313. my $sth;
  1314. my $accno;
  1315. if ($form->{accno}) {
  1316. if ($form->{accno} =~ /^gifi_/) {
  1317. ($null, $accno) = split /_/, $form->{accno};
  1318. $accno = qq| AND ch.gifi_accno = '$accno'|;
  1319. } else {
  1320. $accno = $form->{accno};
  1321. $accno = qq| AND ch.accno = '$accno'|;
  1322. }
  1323. }
  1324. my $table;
  1325. my $ARAP;
  1326. if ($form->{db} eq 'ar') {
  1327. $table = "customer";
  1328. $ARAP = "AR";
  1329. }
  1330. if ($form->{db} eq 'ap') {
  1331. $table = "vendor";
  1332. $ARAP = "AP";
  1333. }
  1334. my $transdate = "a.transdate";
  1335. ($form->{fromdate}, $form->{todate}) = $form->from_to($form->{year}, $form->{month}, $form->{interval}) if $form->{year} && $form->{month};
  1336. # if there are any dates construct a where
  1337. if ($form->{fromdate} || $form->{todate}) {
  1338. if ($form->{fromdate}) {
  1339. $where .= " AND $transdate >= '$form->{fromdate}'";
  1340. }
  1341. if ($form->{todate}) {
  1342. $where .= " AND $transdate <= '$form->{todate}'";
  1343. }
  1344. }
  1345. if ($form->{method} eq 'cash') {
  1346. $transdate = "a.datepaid";
  1347. my $todate = $form->{todate};
  1348. if (! $todate) {
  1349. ($todate) = $dbh->selectrow_array(qq|SELECT current_date FROM defaults|);
  1350. }
  1351. $cashwhere = qq|
  1352. AND ac.trans_id IN
  1353. (
  1354. SELECT trans_id
  1355. FROM acc_trans
  1356. JOIN chart ON (chart_id = chart.id)
  1357. WHERE link LIKE '%${ARAP}_paid%'
  1358. AND $transdate <= '$todate'
  1359. AND a.paid = a.amount
  1360. )
  1361. |;
  1362. }
  1363. my $ml = ($form->{db} eq 'ar') ? 1 : -1;
  1364. my %ordinal = ( 'transdate' => 3,
  1365. 'invnumber' => 4,
  1366. 'name' => 5
  1367. );
  1368. my @a = qw(transdate invnumber name);
  1369. my $sortorder = $form->sort_order(\@a, \%ordinal);
  1370. if ($form->{summary}) {
  1371. $query = qq|SELECT a.id, a.invoice, $transdate AS transdate,
  1372. a.invnumber, n.name, a.netamount,
  1373. ac.amount * $ml AS tax,
  1374. a.till
  1375. FROM acc_trans ac
  1376. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1377. JOIN chart ch ON (ch.id = ac.chart_id)
  1378. JOIN $table n ON (n.id = a.${table}_id)
  1379. WHERE $where
  1380. $accno
  1381. $cashwhere
  1382. |;
  1383. if ($form->{fromdate}) {
  1384. # include open transactions from previous period
  1385. if ($cashwhere) {
  1386. $query .= qq|
  1387. UNION
  1388. SELECT a.id, a.invoice, $transdate AS transdate,
  1389. a.invnumber, n.name, a.netamount,
  1390. ac.amount * $ml AS tax,
  1391. a.till
  1392. FROM acc_trans ac
  1393. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1394. JOIN chart ch ON (ch.id = ac.chart_id)
  1395. JOIN $table n ON (n.id = a.${table}_id)
  1396. WHERE a.datepaid >= '$form->{fromdate}'
  1397. $accno
  1398. $cashwhere
  1399. |;
  1400. }
  1401. }
  1402. } else {
  1403. $query = qq|SELECT a.id, '0' AS invoice, $transdate AS transdate,
  1404. a.invnumber, n.name, a.netamount,
  1405. ac.amount * $ml AS tax,
  1406. a.notes AS description, a.till
  1407. FROM acc_trans ac
  1408. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1409. JOIN chart ch ON (ch.id = ac.chart_id)
  1410. JOIN $table n ON (n.id = a.${table}_id)
  1411. WHERE $where
  1412. $accno
  1413. AND a.invoice = '0'
  1414. $cashwhere
  1415. UNION
  1416. SELECT a.id, '1' AS invoice, $transdate AS transdate,
  1417. a.invnumber, n.name,
  1418. i.sellprice * i.qty * $ml AS netamount,
  1419. i.sellprice * i.qty * $ml *
  1420. (SELECT tx.rate FROM tax tx WHERE tx.chart_id = ch.id AND (tx.validto > $transdate OR tx.validto IS NULL) ORDER BY validto LIMIT 1) AS tax,
  1421. i.description, a.till
  1422. FROM acc_trans ac
  1423. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1424. JOIN chart ch ON (ch.id = ac.chart_id)
  1425. JOIN $table n ON (n.id = a.${table}_id)
  1426. JOIN ${table}tax t ON (t.${table}_id = n.id AND t.chart_id = ch.id)
  1427. JOIN invoice i ON (i.trans_id = a.id)
  1428. JOIN partstax pt ON (pt.parts_id = i.parts_id AND pt.chart_id = ch.id)
  1429. WHERE $where
  1430. $accno
  1431. AND a.invoice = '1'
  1432. $cashwhere
  1433. |;
  1434. if ($form->{fromdate}) {
  1435. if ($cashwhere) {
  1436. $query .= qq|
  1437. UNION
  1438. SELECT a.id, '0' AS invoice, $transdate AS transdate,
  1439. a.invnumber, n.name, a.netamount,
  1440. ac.amount * $ml AS tax,
  1441. a.notes AS description, a.till
  1442. FROM acc_trans ac
  1443. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1444. JOIN chart ch ON (ch.id = ac.chart_id)
  1445. JOIN $table n ON (n.id = a.${table}_id)
  1446. WHERE a.datepaid >= '$form->{fromdate}'
  1447. $accno
  1448. AND a.invoice = '0'
  1449. $cashwhere
  1450. UNION
  1451. SELECT a.id, '1' AS invoice, $transdate AS transdate,
  1452. a.invnumber, n.name,
  1453. i.sellprice * i.qty * $ml AS netamount,
  1454. i.sellprice * i.qty * $ml *
  1455. (SELECT tx.rate FROM tax tx WHERE tx.chart_id = ch.id AND (tx.validto > $transdate OR tx.validto IS NULL) ORDER BY validto LIMIT 1) AS tax,
  1456. i.description, a.till
  1457. FROM acc_trans ac
  1458. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1459. JOIN chart ch ON (ch.id = ac.chart_id)
  1460. JOIN $table n ON (n.id = a.${table}_id)
  1461. JOIN ${table}tax t ON (t.${table}_id = n.id AND t.chart_id = ch.id)
  1462. JOIN invoice i ON (i.trans_id = a.id)
  1463. JOIN partstax pt ON (pt.parts_id = i.parts_id AND pt.chart_id = ch.id)
  1464. WHERE a.datepaid >= '$form->{fromdate}'
  1465. $accno
  1466. AND a.invoice = '1'
  1467. $cashwhere
  1468. |;
  1469. }
  1470. }
  1471. }
  1472. if ($form->{report} =~ /nontaxable/) {
  1473. if ($form->{summary}) {
  1474. # only gather up non-taxable transactions
  1475. $query = qq|SELECT DISTINCT a.id, a.invoice, $transdate AS transdate,
  1476. a.invnumber, n.name, a.netamount, a.till
  1477. FROM acc_trans ac
  1478. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1479. JOIN $table n ON (n.id = a.${table}_id)
  1480. WHERE $where
  1481. AND a.netamount = a.amount
  1482. $cashwhere
  1483. |;
  1484. if ($form->{fromdate}) {
  1485. if ($cashwhere) {
  1486. $query .= qq|
  1487. UNION
  1488. SELECT DISTINCT a.id, a.invoice, $transdate AS transdate,
  1489. a.invnumber, n.name, a.netamount, a.till
  1490. FROM acc_trans ac
  1491. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1492. JOIN $table n ON (n.id = a.${table}_id)
  1493. WHERE a.datepaid >= '$form->{fromdate}'
  1494. AND a.netamount = a.amount
  1495. $cashwhere
  1496. |;
  1497. }
  1498. }
  1499. } else {
  1500. # gather up details for non-taxable transactions
  1501. $query = qq|SELECT a.id, '0' AS invoice, $transdate AS transdate,
  1502. a.invnumber, n.name, a.netamount,
  1503. a.notes AS description, a.till
  1504. FROM acc_trans ac
  1505. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1506. JOIN $table n ON (n.id = a.${table}_id)
  1507. WHERE $where
  1508. AND a.invoice = '0'
  1509. AND a.netamount = a.amount
  1510. $cashwhere
  1511. GROUP BY a.id, $transdate, a.invnumber, n.name, a.netamount,
  1512. a.notes, a.till
  1513. UNION
  1514. SELECT a.id, '1' AS invoice, $transdate AS transdate,
  1515. a.invnumber, n.name,
  1516. sum(ac.sellprice * ac.qty) * $ml AS netamount,
  1517. ac.description, a.till
  1518. FROM invoice ac
  1519. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1520. JOIN $table n ON (n.id = a.${table}_id)
  1521. WHERE $where
  1522. AND a.invoice = '1'
  1523. AND (
  1524. a.${table}_id NOT IN (
  1525. SELECT ${table}_id FROM ${table}tax t (${table}_id)
  1526. ) OR
  1527. ac.parts_id NOT IN (
  1528. SELECT parts_id FROM partstax p (parts_id)
  1529. )
  1530. )
  1531. $cashwhere
  1532. GROUP BY a.id, a.invnumber, $transdate, n.name,
  1533. ac.description, a.till
  1534. |;
  1535. if ($form->{fromdate}) {
  1536. if ($cashwhere) {
  1537. $query .= qq|
  1538. UNION
  1539. SELECT a.id, '0' AS invoice, $transdate AS transdate,
  1540. a.invnumber, n.name, a.netamount,
  1541. a.notes AS description, a.till
  1542. FROM acc_trans ac
  1543. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1544. JOIN $table n ON (n.id = a.${table}_id)
  1545. WHERE a.datepaid >= '$form->{fromdate}'
  1546. AND a.invoice = '0'
  1547. AND a.netamount = a.amount
  1548. $cashwhere
  1549. GROUP BY a.id, $transdate, a.invnumber, n.name, a.netamount,
  1550. a.notes, a.till
  1551. UNION
  1552. SELECT a.id, '1' AS invoice, $transdate AS transdate,
  1553. a.invnumber, n.name,
  1554. sum(ac.sellprice * ac.qty) * $ml AS netamount,
  1555. ac.description, a.till
  1556. FROM invoice ac
  1557. JOIN $form->{db} a ON (a.id = ac.trans_id)
  1558. JOIN $table n ON (n.id = a.${table}_id)
  1559. WHERE a.datepaid >= '$form->{fromdate}'
  1560. AND a.invoice = '1'
  1561. AND (
  1562. a.${table}_id NOT IN (
  1563. SELECT ${table}_id FROM ${table}tax t (${table}_id)
  1564. ) OR
  1565. ac.parts_id NOT IN (
  1566. SELECT parts_id FROM partstax p (parts_id)
  1567. )
  1568. )
  1569. $cashwhere
  1570. GROUP BY a.id, a.invnumber, $transdate, n.name,
  1571. ac.description, a.till
  1572. |;
  1573. }
  1574. }
  1575. }
  1576. }
  1577. $query .= qq|
  1578. ORDER by $sortorder|;
  1579. $sth = $dbh->prepare($query);
  1580. $sth->execute || $form->dberror($query);
  1581. while ( my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  1582. $ref->{tax} = $form->round_amount($ref->{tax}, 2);
  1583. if ($form->{report} =~ /nontaxable/) {
  1584. push @{ $form->{TR} }, $ref if $ref->{netamount};
  1585. } else {
  1586. push @{ $form->{TR} }, $ref if $ref->{tax};
  1587. }
  1588. }
  1589. $sth->finish;
  1590. $dbh->disconnect;
  1591. }
  1592. sub paymentaccounts {
  1593. my ($self, $myconfig, $form) = @_;
  1594. # connect to database, turn AutoCommit off
  1595. my $dbh = $form->dbconnect_noauto($myconfig);
  1596. my $ARAP = uc $form->{db};
  1597. # get A(R|P)_paid accounts
  1598. my $query = qq|SELECT accno, description
  1599. FROM chart
  1600. WHERE link LIKE '%${ARAP}_paid%'
  1601. ORDER BY accno|;
  1602. my $sth = $dbh->prepare($query);
  1603. $sth->execute || $form->dberror($query);
  1604. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  1605. push @{ $form->{PR} }, $ref;
  1606. }
  1607. $sth->finish;
  1608. $form->all_years($myconfig, $dbh);
  1609. $dbh->disconnect;
  1610. }
  1611. sub payments {
  1612. my ($self, $myconfig, $form) = @_;
  1613. # connect to database, turn AutoCommit off
  1614. my $dbh = $form->dbconnect_noauto($myconfig);
  1615. my $ml = 1;
  1616. if ($form->{db} eq 'ar') {
  1617. $table = 'customer';
  1618. $ml = -1;
  1619. }
  1620. if ($form->{db} eq 'ap') {
  1621. $table = 'vendor';
  1622. }
  1623. my $query;
  1624. my $sth;
  1625. my $dpt_join;
  1626. my $where;
  1627. my $var;
  1628. if ($form->{department_id}) {
  1629. $dpt_join = qq|
  1630. JOIN dpt_trans t ON (t.trans_id = ac.trans_id)
  1631. |;
  1632. $where = qq|
  1633. AND t.department_id = $form->{department_id}
  1634. |;
  1635. }
  1636. ($form->{fromdate}, $form->{todate}) = $form->from_to($form->{year}, $form->{month}, $form->{interval}) if $form->{year} && $form->{month};
  1637. if ($form->{fromdate}) {
  1638. $where .= " AND ac.transdate >= '$form->{fromdate}'";
  1639. }
  1640. if ($form->{todate}) {
  1641. $where .= " AND ac.transdate <= '$form->{todate}'";
  1642. }
  1643. if (!$form->{fx_transaction}) {
  1644. $where .= " AND ac.fx_transaction = '0'";
  1645. }
  1646. if ($form->{description} ne "") {
  1647. $var = $form->like(lc $form->{description});
  1648. $where .= " AND lower(c.name) LIKE '$var'";
  1649. }
  1650. if ($form->{source} ne "") {
  1651. $var = $form->like(lc $form->{source});
  1652. $where .= " AND lower(ac.source) LIKE '$var'";
  1653. }
  1654. if ($form->{memo} ne "") {
  1655. $var = $form->like(lc $form->{memo});
  1656. $where .= " AND lower(ac.memo) LIKE '$var'";
  1657. }
  1658. my %ordinal = ( 'name' => 1,
  1659. 'transdate' => 2,
  1660. 'source' => 4,
  1661. 'employee' => 6,
  1662. 'till' => 7
  1663. );
  1664. my @a = qw(name transdate employee);
  1665. my $sortorder = $form->sort_order(\@a, \%ordinal);
  1666. my $glwhere = $where;
  1667. $glwhere =~ s/\(c.name\)/\(g.description\)/;
  1668. # cycle through each id
  1669. foreach my $accno (split(/ /, $form->{paymentaccounts})) {
  1670. $query = qq|SELECT id, accno, description
  1671. FROM chart
  1672. WHERE accno = '$accno'|;
  1673. $sth = $dbh->prepare($query);
  1674. $sth->execute || $form->dberror($query);
  1675. my $ref = $sth->fetchrow_hashref(NAME_lc);
  1676. push @{ $form->{PR} }, $ref;
  1677. $sth->finish;
  1678. $query = qq|SELECT c.name, ac.transdate, sum(ac.amount) * $ml AS paid,
  1679. ac.source, ac.memo, e.name AS employee, a.till, a.curr
  1680. FROM acc_trans ac
  1681. JOIN $form->{db} a ON (ac.trans_id = a.id)
  1682. JOIN $table c ON (c.id = a.${table}_id)
  1683. LEFT JOIN employee e ON (a.employee_id = e.id)
  1684. $dpt_join
  1685. WHERE ac.chart_id = $ref->{id}
  1686. $where|;
  1687. if ($form->{till} ne "") {
  1688. $query .= " AND a.invoice = '1'
  1689. AND NOT a.till IS NULL";
  1690. if ($myconfig->{role} eq 'user') {
  1691. $query .= " AND e.login = '$form->{login}'";
  1692. }
  1693. }
  1694. $query .= qq|
  1695. GROUP BY c.name, ac.transdate, ac.source, ac.memo,
  1696. e.name, a.till, a.curr
  1697. |;
  1698. if ($form->{till} eq "") {
  1699. # don't need gl for a till
  1700. $query .= qq|
  1701. UNION
  1702. SELECT g.description, ac.transdate, sum(ac.amount) * $ml AS paid, ac.source,
  1703. ac.memo, e.name AS employee, '' AS till, '' AS curr
  1704. FROM acc_trans ac
  1705. JOIN gl g ON (g.id = ac.trans_id)
  1706. LEFT JOIN employee e ON (g.employee_id = e.id)
  1707. $dpt_join
  1708. WHERE ac.chart_id = $ref->{id}
  1709. $glwhere
  1710. AND (ac.amount * $ml) > 0
  1711. GROUP BY g.description, ac.transdate, ac.source, ac.memo, e.name
  1712. |;
  1713. }
  1714. $query .= qq|
  1715. ORDER BY $sortorder|;
  1716. $sth = $dbh->prepare($query);
  1717. $sth->execute || $form->dberror($query);
  1718. while (my $pr = $sth->fetchrow_hashref(NAME_lc)) {
  1719. push @{ $form->{$ref->{id}} }, $pr;
  1720. }
  1721. $sth->finish;
  1722. }
  1723. $dbh->disconnect;
  1724. }
  1725. 1;