summaryrefslogtreecommitdiff
path: root/LedgerSMB/RC.pm
blob: 5952a2cedb6b759f179f72ee6c39abc9f645e248 (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) 2002
  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. # Account reconciliation routines
  30. #
  31. #======================================================================
  32. package RC;
  33. sub paymentaccounts {
  34. my ($self, $myconfig, $form) = @_;
  35. # connect to database
  36. my $dbh = $form->dbconnect($myconfig);
  37. my $query = qq|SELECT accno, description
  38. FROM chart
  39. WHERE link LIKE '%_paid%'
  40. AND (category = 'A' OR category = 'L')
  41. ORDER BY accno|;
  42. my $sth = $dbh->prepare($query);
  43. $sth->execute || $form->dberror($query);
  44. while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
  45. push @{ $form->{PR} }, $ref;
  46. }
  47. $sth->finish;
  48. $form->all_years($myconfig, $dbh);
  49. $dbh->disconnect;
  50. }
  51. sub payment_transactions {
  52. my ($self, $myconfig, $form) = @_;
  53. # connect to database, turn AutoCommit off
  54. my $dbh = $form->dbconnect_noauto($myconfig);
  55. my $query;
  56. my $sth;
  57. $query = qq|SELECT category FROM chart
  58. WHERE accno = '$form->{accno}'|;
  59. ($form->{category}) = $dbh->selectrow_array($query);
  60. my $cleared;
  61. ($form->{fromdate}, $form->{todate}) = $form->from_to($form->{year}, $form->{month}, $form->{interval}) if $form->{year} && $form->{month};
  62. my $transdate = qq| AND ac.transdate < date '$form->{fromdate}'|;
  63. if (! $form->{fromdate}) {
  64. $cleared = qq| AND ac.cleared = '1'|;
  65. $transdate = "";
  66. }
  67. # get beginning balance
  68. $query = qq|SELECT sum(ac.amount)
  69. FROM acc_trans ac
  70. JOIN chart ch ON (ch.id = ac.chart_id)
  71. WHERE ch.accno = '$form->{accno}'
  72. $transdate
  73. $cleared
  74. |;
  75. ($form->{beginningbalance}) = $dbh->selectrow_array($query);
  76. # fx balance
  77. $query = qq|SELECT sum(ac.amount)
  78. FROM acc_trans ac
  79. JOIN chart ch ON (ch.id = ac.chart_id)
  80. WHERE ch.accno = '$form->{accno}'
  81. AND ac.fx_transaction = '1'
  82. $transdate
  83. $cleared
  84. |;
  85. ($form->{fx_balance}) = $dbh->selectrow_array($query);
  86. $transdate = "";
  87. if ($form->{todate}) {
  88. $transdate = qq| AND ac.transdate <= date '$form->{todate}'|;
  89. }
  90. # get statement balance
  91. $query = qq|SELECT sum(ac.amount)
  92. FROM acc_trans ac
  93. JOIN chart ch ON (ch.id = ac.chart_id)
  94. WHERE ch.accno = '$form->{accno}'
  95. $transdate
  96. |;
  97. ($form->{endingbalance}) = $dbh->selectrow_array($query);
  98. # fx balance
  99. $query = qq|SELECT sum(ac.amount)
  100. FROM acc_trans ac
  101. JOIN chart ch ON (ch.id = ac.chart_id)
  102. WHERE ch.accno = '$form->{accno}'
  103. AND ac.fx_transaction = '1'
  104. $transdate
  105. |;
  106. ($form->{fx_endingbalance}) = $dbh->selectrow_array($query);
  107. $cleared = qq| AND ac.cleared = '0'| unless $form->{fromdate};
  108. if ($form->{report}) {
  109. $cleared = qq| AND NOT (ac.cleared = '0' OR ac.cleared = '1')|;
  110. if ($form->{cleared}) {
  111. $cleared = qq| AND ac.cleared = '1'|;
  112. }
  113. if ($form->{outstanding}) {
  114. $cleared = ($form->{cleared}) ? "" : qq| AND ac.cleared = '0'|;
  115. }
  116. if (! $form->{fromdate}) {
  117. $form->{beginningbalance} = 0;
  118. $form->{fx_balance} = 0;
  119. }
  120. }
  121. my $fx_transaction;
  122. if ($form->{fx_transaction}) {
  123. $fx_transaction = qq|
  124. AND NOT
  125. (ac.chart_id IN
  126. (SELECT fxgain_accno_id FROM defaults
  127. UNION
  128. SELECT fxloss_accno_id FROM defaults))|;
  129. } else {
  130. $fx_transaction = qq|
  131. AND ac.fx_transaction = '0'|;
  132. }
  133. if ($form->{summary}) {
  134. $query = qq|SELECT ac.transdate, ac.source,
  135. sum(ac.amount) AS amount, ac.cleared
  136. FROM acc_trans ac
  137. JOIN chart ch ON (ac.chart_id = ch.id)
  138. WHERE ch.accno = '$form->{accno}'
  139. AND ac.amount >= 0
  140. $fx_transaction
  141. $cleared|;
  142. $query .= " AND ac.transdate >= '$form->{fromdate}'" if $form->{fromdate};
  143. $query .= " AND ac.transdate <= '$form->{todate}'" if $form->{todate};
  144. $query .= " GROUP BY ac.source, ac.transdate, ac.cleared";
  145. $query .= qq|
  146. UNION ALL
  147. SELECT ac.transdate, ac.source,
  148. sum(ac.amount) AS amount, ac.cleared
  149. FROM acc_trans ac
  150. JOIN chart ch ON (ac.chart_id = ch.id)
  151. WHERE ch.accno = '$form->{accno}'
  152. AND ac.amount < 0
  153. $fx_transaction
  154. $cleared|;
  155. $query .= " AND ac.transdate >= '$form->{fromdate}'" if $form->{fromdate};
  156. $query .= " AND ac.transdate <= '$form->{todate}'" if $form->{todate};
  157. $query .= " GROUP BY ac.source, ac.transdate, ac.cleared";
  158. $query .= " ORDER BY 1,2";
  159. } else {
  160. $query = qq|SELECT ac.transdate, ac.source, ac.fx_transaction,
  161. ac.amount, ac.cleared, g.id, g.description
  162. FROM acc_trans ac
  163. JOIN chart ch ON (ac.chart_id = ch.id)
  164. JOIN gl g ON (g.id = ac.trans_id)
  165. WHERE ch.accno = '$form->{accno}'
  166. $fx_transaction
  167. $cleared|;
  168. $query .= " AND ac.transdate >= '$form->{fromdate}'" if $form->{fromdate};
  169. $query .= " AND ac.transdate <= '$form->{todate}'" if $form->{todate};
  170. $query .= qq|
  171. UNION ALL
  172. SELECT ac.transdate, ac.source, ac.fx_transaction,
  173. ac.amount, ac.cleared, a.id, n.name
  174. FROM acc_trans ac
  175. JOIN chart ch ON (ac.chart_id = ch.id)
  176. JOIN ar a ON (a.id = ac.trans_id)
  177. JOIN customer n ON (n.id = a.customer_id)
  178. WHERE ch.accno = '$form->{accno}'
  179. $fx_transaction
  180. $cleared|;
  181. $query .= " AND ac.transdate >= '$form->{fromdate}'" if $form->{fromdate};
  182. $query .= " AND ac.transdate <= '$form->{todate}'" if $form->{todate};
  183. $query .= qq|
  184. UNION ALL
  185. SELECT ac.transdate, ac.source, ac.fx_transaction,
  186. ac.amount, ac.cleared, a.id, n.name
  187. FROM acc_trans ac
  188. JOIN chart ch ON (ac.chart_id = ch.id)
  189. JOIN ap a ON (a.id = ac.trans_id)
  190. JOIN vendor n ON (n.id = a.vendor_id)
  191. WHERE ch.accno = '$form->{accno}'
  192. $fx_transaction
  193. $cleared|;
  194. $query .= " AND ac.transdate >= '$form->{fromdate}'" if $form->{fromdate};
  195. $query .= " AND ac.transdate <= '$form->{todate}'" if $form->{todate};
  196. $query .= " ORDER BY 1,2,3";
  197. }
  198. $sth = $dbh->prepare($query);
  199. $sth->execute || $form->dberror($query);
  200. my $dr;
  201. my $cr;
  202. if ($form->{summary}) {
  203. $query = qq|SELECT c.name
  204. FROM customer c
  205. JOIN ar a ON (c.id = a.customer_id)
  206. JOIN acc_trans ac ON (a.id = ac.trans_id)
  207. JOIN chart ch ON (ac.chart_id = ch.id)
  208. WHERE ac.transdate = ?
  209. AND ch.accno = '$form->{accno}'
  210. AND (ac.source = ? OR ac.source IS NULL)
  211. AND ac.amount >= 0
  212. $cleared
  213. UNION
  214. SELECT v.name
  215. FROM vendor v
  216. JOIN ap a ON (v.id = a.vendor_id)
  217. JOIN acc_trans ac ON (a.id = ac.trans_id)
  218. JOIN chart ch ON (ac.chart_id = ch.id)
  219. WHERE ac.transdate = ?
  220. AND ch.accno = '$form->{accno}'
  221. AND (ac.source = ? OR ac.source IS NULL)
  222. AND ac.amount > 0
  223. $cleared
  224. UNION
  225. SELECT g.description
  226. FROM gl g
  227. JOIN acc_trans ac ON (g.id = ac.trans_id)
  228. JOIN chart ch ON (ac.chart_id = ch.id)
  229. WHERE ac.transdate = ?
  230. AND ch.accno = '$form->{accno}'
  231. AND (ac.source = ? OR ac.source IS NULL)
  232. AND ac.amount >= 0
  233. $cleared
  234. |;
  235. $query .= " ORDER BY 1";
  236. $dr = $dbh->prepare($query);
  237. $query = qq|SELECT c.name
  238. FROM customer c
  239. JOIN ar a ON (c.id = a.customer_id)
  240. JOIN acc_trans ac ON (a.id = ac.trans_id)
  241. JOIN chart ch ON (ac.chart_id = ch.id)
  242. WHERE ac.transdate = ?
  243. AND ch.accno = '$form->{accno}'
  244. AND (ac.source = ? OR ac.source IS NULL)
  245. AND ac.amount < 0
  246. $cleared
  247. UNION
  248. SELECT v.name
  249. FROM vendor v
  250. JOIN ap a ON (v.id = a.vendor_id)
  251. JOIN acc_trans ac ON (a.id = ac.trans_id)
  252. JOIN chart ch ON (ac.chart_id = ch.id)
  253. WHERE ac.transdate = ?
  254. AND ch.accno = '$form->{accno}'
  255. AND (ac.source = ? OR ac.source IS NULL)
  256. AND ac.amount < 0
  257. $cleared
  258. UNION
  259. SELECT g.description
  260. FROM gl g
  261. JOIN acc_trans ac ON (g.id = ac.trans_id)
  262. JOIN chart ch ON (ac.chart_id = ch.id)
  263. WHERE ac.transdate = ?
  264. AND ch.accno = '$form->{accno}'
  265. AND (ac.source = ? OR ac.source IS NULL)
  266. AND ac.amount < 0
  267. $cleared
  268. |;
  269. $query .= " ORDER BY 1";
  270. $cr = $dbh->prepare($query);
  271. }
  272. my $name;
  273. my $ref;
  274. while ($ref = $sth->fetchrow_hashref(NAME_lc)) {
  275. if ($form->{summary}) {
  276. if ($ref->{amount} > 0) {
  277. $dr->execute($ref->{transdate}, $ref->{source}, $ref->{transdate}, $ref->{source}, $ref->{transdate}, $ref->{source});
  278. $ref->{oldcleared} = $ref->{cleared};
  279. $ref->{name} = ();
  280. while (($name) = $dr->fetchrow_array) {
  281. push @{ $ref->{name} }, $name;
  282. }
  283. $dr->finish;
  284. } else {
  285. $cr->execute($ref->{transdate}, $ref->{source}, $ref->{transdate}, $ref->{source}, $ref->{transdate}, $ref->{source});
  286. $ref->{oldcleared} = $ref->{cleared};
  287. $ref->{name} = ();
  288. while (($name) = $cr->fetchrow_array) {
  289. push @{ $ref->{name} }, $name;
  290. }
  291. $cr->finish;
  292. }
  293. } else {
  294. push @{ $ref->{name} }, $ref->{description};
  295. }
  296. push @{ $form->{PR} }, $ref;
  297. }
  298. $sth->finish;
  299. $dbh->disconnect;
  300. }
  301. sub reconcile {
  302. my ($self, $myconfig, $form) = @_;
  303. # connect to database
  304. my $dbh = $form->dbconnect($myconfig);
  305. my $query = qq|SELECT id FROM chart
  306. WHERE accno = '$form->{accno}'|;
  307. my ($chart_id) = $dbh->selectrow_array($query);
  308. $chart_id *= 1;
  309. $query = qq|SELECT trans_id FROM acc_trans
  310. WHERE (source = ? OR source IS NULL)
  311. AND transdate = ?
  312. AND cleared = '0'
  313. AND chart_id = $chart_id|;
  314. my $sth = $dbh->prepare($query) || $form->dberror($query);
  315. my $i;
  316. my $trans_id;
  317. $query = qq|UPDATE acc_trans SET cleared = '1'
  318. WHERE cleared = '0'
  319. AND trans_id = ?
  320. AND transdate = ?
  321. AND chart_id = $chart_id|;
  322. my $tth = $dbh->prepare($query) || $form->dberror($query);
  323. # clear flags
  324. for $i (1 .. $form->{rowcount}) {
  325. if ($form->{"cleared_$i"} && ! $form->{"oldcleared_$i"}) {
  326. if ($form->{summary}) {
  327. $sth->execute($form->{"source_$i"}, $form->{"transdate_$i"}) || $form->dberror;
  328. while (($trans_id) = $sth->fetchrow_array) {
  329. $tth->execute($trans_id, $form->{"transdate_$i"}) || $form->dberror;
  330. $tth->finish;
  331. }
  332. $sth->finish;
  333. } else {
  334. $tth->execute($form->{"id_$i"}, $form->{"transdate_$i"}) || $form->dberror;
  335. $tth->finish;
  336. }
  337. }
  338. }
  339. $dbh->disconnect;
  340. }
  341. 1;