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