File: RC.pm

package info (click to toggle)
sql-ledger 3.0.8-1
  • links: PTS, VCS
  • area: main
  • in suites: stretch
  • size: 35,524 kB
  • ctags: 4,556
  • sloc: perl: 64,519; sql: 28,330; sh: 34; makefile: 21
file content (333 lines) | stat: -rw-r--r-- 8,517 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
#=====================================================================
# SQL-Ledger ERP
# Copyright (C) 2006
#
#  Author: DWS Systems Inc.
#     Web: http://www.sql-ledger.com
#
#======================================================================
#
# Account reconciliation routines
#
#======================================================================

package RC;


sub paymentaccounts {
  my ($self, $myconfig, $form) = @_;

  # connect to database
  my $dbh = $form->dbconnect($myconfig);

  my $query = qq|SELECT c.accno, c.description,
                 l.description AS translation
                 FROM chart c
		 LEFT JOIN translation l ON (l.trans_id = c.id AND l.language_code = '$myconfig->{countrycode}')
		 WHERE c.charttype = 'A'
		 ORDER BY c.accno|;
  my $sth = $dbh->prepare($query);
  $sth->execute || $form->dberror($query);

  while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {
    $ref->{description} = $ref->{translation} if $ref->{translation};
    push @{ $form->{PR} }, $ref;
  }
  $sth->finish;

  $form->all_years($myconfig, $dbh);

  $dbh->disconnect;

}


sub payment_transactions {
  my ($self, $myconfig, $form) = @_;

  # connect to database, turn AutoCommit off
  my $dbh = $form->dbconnect_noauto($myconfig);
  
  my $query = qq|SELECT category FROM chart
                 WHERE accno = '$form->{accno}'|;
  ($form->{category}) = $dbh->selectrow_array($query);

  ($form->{fromdate}, $form->{todate}) = $form->from_to($form->{year}, $form->{month}, $form->{interval}) if $form->{year} && $form->{month};

  my $cleared;
  if ($form->{todate}) {
    $form->{recdate} = $form->current_date($myconfig, $form->{todate});
  } else {
    $form->{recdate} = $form->current_date($myconfig);
  }
   
  my $transdate = "";

  if ($form->{fromdate}) {
    $transdate = qq| AND ac.transdate < date '$form->{fromdate}'|;
    $cleared = qq| AND ac.cleared < date '$form->{fromdate}'|;
  } else {
    $cleared = qq| AND ac.cleared IS NOT NULL|;
  }
  
  # get beginning balance
  $query = qq|SELECT sum(ac.amount)
	      FROM acc_trans ac
	      JOIN chart ch ON (ch.id = ac.chart_id)
	      WHERE ch.accno = '$form->{accno}'
	      AND ac.approved = '1'
	      $transdate
	      $cleared
	      |;
  ($form->{beginningbalance}) = $dbh->selectrow_array($query) if $form->{fromdate};

  # fx balance
  $query = qq|SELECT sum(ac.amount)
	      FROM acc_trans ac
	      JOIN chart ch ON (ch.id = ac.chart_id)
	      WHERE ch.accno = '$form->{accno}'
	      AND ac.approved = '1'
	      AND ac.fx_transaction = '1'
	      $transdate
	      $cleared
	      |;
  ($form->{fx_balance}) = $dbh->selectrow_array($query) if $form->{fromdate};
  

  $transdate = "";
  $cleared = "";
  if ($form->{todate}) {
    $transdate = qq| AND ac.transdate <= date '$form->{todate}'|;
    $cleared = qq| AND ac.cleared <= date '$form->{todate}'|;
  }
 
  # get statement balance
  $query = qq|SELECT sum(ac.amount)
	      FROM acc_trans ac
	      JOIN chart ch ON (ch.id = ac.chart_id)
	      WHERE ch.accno = '$form->{accno}'
	      AND ac.approved = '1'
	      $transdate
	      $cleared
	      |;
  ($form->{endingbalance}) = $dbh->selectrow_array($query);


  # fx balance
  $query = qq|SELECT sum(ac.amount)
	      FROM acc_trans ac
	      JOIN chart ch ON (ch.id = ac.chart_id)
	      WHERE ch.accno = '$form->{accno}'
	      AND ac.approved = '1'
	      AND ac.fx_transaction = '1'
	      $transdate
	      $cleared
	      |;
  ($form->{fx_endingbalance}) = $dbh->selectrow_array($query);
  
  my %defaults = $form->get_defaults($dbh, \@{['fx%_accno_id','precision', 'company']});
  for (qw(precision company)) { $form->{$_} = $defaults{$_} }
 
  my $fx_transaction;
  if ($form->{fx_transaction}) {
   
    $fx_transaction = qq|
	      AND NOT
		 (ac.chart_id = $defaults{fxgain_accno_id}
		  OR ac.chart_id = $defaults{fxloss_accno_id}
		 )|;
		 
  } else {
    $fx_transaction = qq|
	      AND ac.fx_transaction = '0'|;
  }
 
  $transdate = "";
  $cleared = "";
  
  if ($form->{fromdate}) {
    $transdate .= qq| AND (ac.transdate >= '$form->{fromdate}' OR ac.cleared >= '$form->{fromdate}')|;
  }
  if ($form->{todate}) {
    $transdate .= qq| AND ac.transdate <= '$form->{todate}'|;
  }
 
  if ($form->{report}) {
    if (!$form->{fromdate}) {
      $form->{beginningbalance} = 0;
      $form->{fx_balance} = 0;
    }
  }
  
  if ($form->{report}) {
    $transdate = "";
    $cleared = qq| AND ac.cleared IS NOT NULL|;
    if ($form->{fromdate} || $form->{todate}) {
      $cleared = "";
      if ($form->{fromdate}) {
	$cleared = qq| AND ac.cleared >= '$form->{fromdate}'|;
      }
      if ($form->{todate}) {
	$cleared .= qq| AND ac.cleared <= '$form->{todate}'|;
      }
    }
  }

  my $union;
  
  $query = "";
  
  for (1 .. 2) {
    $query .= qq|$union
		SELECT ac.transdate, ac.source, ac.fx_transaction,
		ac.amount, ac.cleared, g.id, g.description
		FROM acc_trans ac
		JOIN chart ch ON (ac.chart_id = ch.id)
		JOIN gl g ON (g.id = ac.trans_id)
		WHERE ch.accno = '$form->{accno}'
		AND ac.approved = '1'
		$fx_transaction
		$transdate
		$cleared
		UNION
		SELECT ac.transdate, ac.source, ac.fx_transaction,
		ac.amount, ac.cleared, a.id, n.name
		FROM acc_trans ac
		JOIN chart ch ON (ac.chart_id = ch.id)
		JOIN ar a ON (a.id = ac.trans_id)
		JOIN customer n ON (n.id = a.customer_id)
		WHERE ch.accno = '$form->{accno}'
		AND ac.approved = '1'
		$fx_transaction
		$transdate
		$cleared
		UNION
		SELECT ac.transdate, ac.source, ac.fx_transaction,
		ac.amount, ac.cleared, a.id, n.name
		FROM acc_trans ac
		JOIN chart ch ON (ac.chart_id = ch.id)
		JOIN ap a ON (a.id = ac.trans_id)
		JOIN vendor n ON (n.id = a.vendor_id)
		WHERE ch.accno = '$form->{accno}'
		AND ac.approved = '1'
		$fx_transaction
		$transdate
		$cleared|;

    last if $form->{report};
    
    $union = "UNION ALL";
    
    $transdate = "";
    if ($form->{fromdate}) {
      $transdate = qq| AND ac.transdate < '$form->{fromdate}'|;
    }
    if ($form->{todate}) {
      $transdate .= qq| AND ac.transdate < '$form->{todate}'|;
    }
   
    $cleared = qq| AND ac.cleared IS NULL|;
  }
  
  $query .= " ORDER BY 1,2,3";

  my $sth = $dbh->prepare($query);
  $sth->execute || $form->dberror($query);

  my $sameitem;
  my $samename;
  my $i = -1;
  my $sw;
  
  while (my $ref = $sth->fetchrow_hashref(NAME_lc)) {

    if ($i == -1) {
      $sw = $ref->{amount};
    }

    $ref->{oldcleared} = $ref->{cleared};
    
    if ($form->{summary}) {

      if ($ref->{amount} > 0 && $sw < 0) {
	$sameitem = "";
	$sw = $ref->{amount};
      }
      if ($ref->{amount} < 0 && $sw > 0) {
	$sameitem = "";
	$sw = $ref->{amount};
      }
      
      if ("$ref->{transdate}$ref->{source}" eq $sameitem) {
	if ($ref->{fx_transaction}) {
	  $form->{PR}->[$i]->{amount} += $ref->{amount};
	} else {
	  push @{ $form->{PR}->[$i]->{name} }, $ref->{description} if $ref->{description} ne $samename;
	  $form->{PR}->[$i]->{amount} += $ref->{amount};
	  $form->{PR}->[$i]->{id} .= " $ref->{id}" if $form->{PR}->[$i]->{id} !~ /$ref->{id}/;
	}
      } else {
	push @{ $ref->{name} }, $ref->{description};
	push @{ $form->{PR} }, $ref;
	$i++;
      }

    } else {
      push @{ $ref->{name} }, $ref->{description};
      push @{ $form->{PR} }, $ref;
    }

    $sameitem = "$ref->{transdate}$ref->{source}";
    $samename = $ref->{description};

  }
  $sth->finish;

  $dbh->disconnect;
  
}


sub reconcile {
  my ($self, $myconfig, $form) = @_;

  # connect to database
  my $dbh = $form->dbconnect($myconfig);

  my $query = qq|SELECT id FROM chart
                 WHERE accno = '$form->{accno}'|;
  my ($chart_id) = $dbh->selectrow_array($query);
  $chart_id *= 1;
  
  my $i;
  my $trans_id;
  my $cleared;
  my $source;

  # clear flags
  for $i (1 .. $form->{rowcount}) {
    if ($form->{"datecleared_$i"} ne $form->{"oldcleared_$i"}) {

      $cleared = ($form->{"cleared_$i"}) ? $form->{recdate} : '';
      $cleared = $form->dbquote($cleared, SQL_DATE);
      $source = ($form->{"source_$i"}) ? qq|AND source = |.$dbh->quote($form->{"source_$i"}) : qq|AND (source = '' OR source IS NULL)|;

      foreach $trans_id (split / /, $form->{"id_$i"}) {
	$query = qq|UPDATE acc_trans SET
	            cleared = $cleared
                    WHERE trans_id = $trans_id 
	            AND transdate = |.$form->dbquote($form->{"transdate_$i"}, SQL_DATE).qq|
	            AND chart_id = $chart_id
                    $source|;
        $dbh->do($query) || $form->dberror($query);
      }
      
    }
  }

  $dbh->disconnect;

}

1;