summaryrefslogtreecommitdiff
path: root/FS/FS/Report/Table/Monthly.pm
blob: 145f2a85c60da85b0d4880e520a6e9f6de1930e8 (plain)
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
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
package FS::Report::Table::Monthly;

use strict;
use vars qw( @ISA $expenses_kludge );
use Time::Local;
use FS::UID qw( dbh );
use FS::Report::Table;
use FS::CurrentUser;

@ISA = qw( FS::Report::Table );

$expenses_kludge = 0;

=head1 NAME

FS::Report::Table::Monthly - Tables of report data, indexed monthly

=head1 SYNOPSIS

  use FS::Report::Table::Monthly;

  my $report = new FS::Report::Table::Monthly (
    'items' => [ 'invoiced', 'netsales', 'credits', 'receipts', ],
    'start_month' => 4,
    'start_year'  => 2000,
    'end_month'   => 4,
    'end_year'    => 2020,
    #opt
    'agentnum'    => 54
    'params'      => [ [ 'paramsfor', 'item_one' ], [ 'item', 'two' ] ], # ...
    'remove_empty' => 1, #collapse empty rows, default 0
    'item_labels' => [ ], #useful with remove_empty
  );

  my $data = $report->data;

=head1 METHODS

=over 4

=item data

Returns a hashref of data (!! describe)

=cut

sub data {
  my $self = shift;

  #use Data::Dumper;
  #warn Dumper($self);

  my $smonth = $self->{'start_month'};
  my $syear = $self->{'start_year'};
  my $emonth = $self->{'end_month'};
  my $eyear = $self->{'end_year'};
  my $agentnum = $self->{'agentnum'};

  my %data;

  while ( $syear < $eyear || ( $syear == $eyear && $smonth < $emonth+1 ) ) {

    push @{$data{label}}, "$smonth/$syear";

    my $speriod = timelocal(0,0,0,1,$smonth-1,$syear);
    push @{$data{speriod}}, $speriod;
    if ( ++$smonth == 13 ) { $syear++; $smonth=1; }
    my $eperiod = timelocal(0,0,0,1,$smonth-1,$syear);
    push @{$data{eperiod}}, $eperiod;
  
    my $col = 0;
    my @row = ();
    foreach my $item ( @{$self->{'items'}} ) {
      my @param = $self->{'params'} ? @{ $self->{'params'}[$col] }: ();
      my $value = $self->$item($speriod, $eperiod, $agentnum, @param);
      #push @{$data{$item}}, $value;
      push @{$data{data}->[$col++]}, $value;
    }

  }

  #these need to get generalized, sheesh
  $data{'items'}       = $self->{'items'};
  $data{'item_labels'} = $self->{'item_labels'} || $self->{'items'};
  $data{'colors'}      = $self->{'colors'};
  $data{'links'}       = $self->{'links'} || [];

  #use Data::Dumper;
  #warn Dumper(\%data);

  if ( $self->{'remove_empty'} ) {

    #warn "removing empty rows\n";

    my $col = 0;
    #these need to get generalized, sheesh
    my @newitems = ();
    my @newlabels = ();
    my @newdata = ();
    my @newcolors = ();
    my @newlinks = ();
    foreach my $item ( @{$self->{'items'}} ) {

      if ( grep { $_ != 0 } @{$data{'data'}->[$col]} ) {
        push @newitems,  $data{'items'}->[$col];
        push @newlabels, $data{'item_labels'}->[$col];
        push @newdata,   $data{'data'}->[$col];
        push @newcolors, $data{'colors'}->[$col];
        push @newlinks,  $data{'links'}->[$col];
      }

      $col++;
    }

    $data{'items'}       = \@newitems;
    $data{'item_labels'} = \@newlabels;
    $data{'data'}        = \@newdata;
    $data{'colors'}      = \@newcolors;
    $data{'links'}       = \@newlinks;

  }

  #use Data::Dumper;
  #warn Dumper(\%data);

  \%data;

}

sub invoiced { #invoiced
  my( $self, $speriod, $eperiod, $agentnum ) = @_;

  $self->scalar_sql("
    SELECT SUM(charged)
      FROM cust_bill
        LEFT JOIN cust_main USING ( custnum )
      WHERE ". $self->in_time_period_and_agent($speriod, $eperiod, $agentnum)
  );
  
}

sub netsales { #net sales
  my( $self, $speriod, $eperiod, $agentnum ) = @_;

  my $credited = $self->scalar_sql("
    SELECT SUM(cust_credit_bill.amount)
      FROM cust_credit_bill
        LEFT JOIN cust_bill USING ( invnum  )
        LEFT JOIN cust_main USING ( custnum )
    WHERE ".  $self->in_time_period_and_agent($speriod, $eperiod, $agentnum, 'cust_bill')
  );

  #horrible local kludge
  my $expenses = !$expenses_kludge ? 0 : $self->scalar_sql("
    SELECT SUM(cust_bill_pkg.setup)
      FROM cust_bill_pkg
        LEFT JOIN cust_bill USING ( invnum  )
        LEFT JOIN cust_main USING ( custnum )
        LEFT JOIN cust_pkg  USING ( pkgnum  )
        LEFT JOIN part_pkg  USING ( pkgpart )
      WHERE ". $self->in_time_period_and_agent($speriod, $eperiod, $agentnum, 'cust_bill'). "
        AND LOWER(part_pkg.pkg) LIKE 'expense _%'
  ");

  $self->invoiced($speriod,$eperiod,$agentnum) - $credited - $expenses;
}

#deferred revenue

sub receipts { #cashflow
  my( $self, $speriod, $eperiod, $agentnum ) = @_;

  my $refunded = $self->scalar_sql("
    SELECT SUM(refund)
      FROM cust_refund
        LEFT JOIN cust_main USING ( custnum )
      WHERE ". $self->in_time_period_and_agent($speriod, $eperiod, $agentnum)
  );

  #horrible local kludge that doesn't even really work right
  my $expenses = !$expenses_kludge ? 0 : $self->scalar_sql("
    SELECT SUM(cust_bill_pay.amount)
      FROM cust_bill_pay
        LEFT JOIN cust_bill USING ( invnum  )
        LEFT JOIN cust_main USING ( custnum )
    WHERE ". $self->in_time_period_and_agent($speriod, $eperiod, $agentnum, 'cust_bill_pay'). "
    AND 0 < ( SELECT COUNT(*) from cust_bill_pkg, cust_pkg, part_pkg
              WHERE cust_bill.invnum = cust_bill_pkg.invnum
              AND cust_pkg.pkgnum = cust_bill_pkg.pkgnum
              AND cust_pkg.pkgpart = part_pkg.pkgpart
              AND LOWER(part_pkg.pkg) LIKE 'expense _%'
            )
  ");
  #    my $expenses_sql2 = "SELECT SUM(cust_bill_pay.amount) FROM cust_bill_pay, cust_bill_pkg, cust_bill, cust_pkg, part_pkg WHERE cust_bill_pay.invnum = cust_bill.invnum AND cust_bill.invnum = cust_bill_pkg.invnum AND cust_bill_pay._date >= $speriod AND cust_bill_pay._date < $eperiod AND cust_pkg.pkgnum = cust_bill_pkg.pkgnum AND cust_pkg.pkgpart = part_pkg.pkgpart AND LOWER(part_pkg.pkg) LIKE 'expense _%'";
  
  $self->payments($speriod, $eperiod, $agentnum) - $refunded - $expenses;
}

sub payments {
  my( $self, $speriod, $eperiod, $agentnum ) = @_;
  $self->scalar_sql("
    SELECT SUM(paid)
      FROM cust_pay
        LEFT JOIN cust_main USING ( custnum )
      WHERE ". $self->in_time_period_and_agent($speriod, $eperiod, $agentnum)
  );
}

sub credits {
  my( $self, $speriod, $eperiod, $agentnum ) = @_;
  $self->scalar_sql("
    SELECT SUM(amount)
      FROM cust_credit
        LEFT JOIN cust_main USING ( custnum )
      WHERE ". $self->in_time_period_and_agent($speriod, $eperiod, $agentnum)
  );
}

#these should be auto-generated or $AUTOLOADed or something
sub invoiced_12mo {
  my( $self, $speriod, $eperiod, $agentnum ) = @_;
  $speriod = $self->_subtract_11mo($speriod);
  $self->invoiced($speriod, $eperiod, $agentnum);
}

sub netsales_12mo {
  my( $self, $speriod, $eperiod, $agentnum ) = @_;
  $speriod = $self->_subtract_11mo($speriod);
  $self->netsales($speriod, $eperiod, $agentnum);
}

sub receipts_12mo {
  my( $self, $speriod, $eperiod, $agentnum ) = @_;
  $speriod = $self->_subtract_11mo($speriod);
  $self->receipts($speriod, $eperiod, $agentnum);
}

sub payments_12mo {
  my( $self, $speriod, $eperiod, $agentnum ) = @_;
  $speriod = $self->_subtract_11mo($speriod);
  $self->payments($speriod, $eperiod, $agentnum);
}

sub credits_12mo {
  my( $self, $speriod, $eperiod, $agentnum ) = @_;
  $speriod = $self->_subtract_11mo($speriod);
  $self->credits($speriod, $eperiod, $agentnum);
}

#not being too bad with the false laziness
use Time::Local qw(timelocal);
sub _subtract_11mo {
  my($self, $time) = @_;
  my ($sec,$min,$hour,$mday,$mon,$year) = (localtime($time) )[0,1,2,3,4,5];
  $mon -= 11;
  if ( $mon < 0 ) { $mon+=12; $year--; }
  timelocal($sec,$min,$hour,$mday,$mon,$year);
}

sub cust_bill_pkg {
  my( $self, $speriod, $eperiod, $agentnum, %opt ) = @_;

  my $where = '';
  if ( $opt{'classnum'} =~ /^(\d+)$/ ) {
    if ( $1 == 0 ) {
      $where = "classnum IS NULL";
    } else {
      $where = "classnum = $1";
    }
  }

  $agentnum ||= $opt{'agentnum'};

  $self->scalar_sql("
    SELECT SUM(cust_bill_pkg.setup + cust_bill_pkg.recur)
      FROM cust_bill_pkg
        LEFT JOIN cust_bill USING ( invnum )
        LEFT JOIN cust_main USING ( custnum )
        LEFT JOIN cust_pkg USING ( pkgnum )
        LEFT JOIN part_pkg USING ( pkgpart )
      WHERE pkgnum != 0
        AND $where
        AND ". $self->in_time_period_and_agent($speriod, $eperiod, $agentnum)
  );
  
}

# NEEDS TO BE AGENTNUM-capable
sub canceled { #active
  my( $self, $speriod, $eperiod, $agentnum ) = @_;
  $self->scalar_sql("
    SELECT COUNT(*)
      FROM cust_pkg
        LEFT JOIN cust_main USING ( custnum )
      WHERE 0 = ( SELECT COUNT(*)
                    FROM cust_pkg
                    WHERE cust_pkg.custnum = cust_main.custnum
                      AND ( cust_pkg.cancel IS NULL OR cust_pkg.cancel = 0 )
                )
        AND cust_pkg.cancel > $speriod AND cust_pkg.cancel < $eperiod
  ");
}
 
# NEEDS TO BE AGENTNUM-capable
sub newaccount { #newaccount
  my( $self, $speriod, $eperiod, $agentnum ) = @_;
  $self->scalar_sql("
     SELECT COUNT(*) FROM cust_pkg
     WHERE cust_pkg.custnum = cust_main.custnum
     AND ( cust_pkg.cancel IS NULL OR cust_pkg.cancel = 0 )
     AND ( cust_pkg.susp IS NULL OR cust_pkg.susp = 0 )
     AND cust_pkg.setup > $speriod AND cust_pkg.setup < $eperiod
  ");
}
 
# NEEDS TO BE AGENTNUM-capable
sub suspended { #suspended
  my( $self, $speriod, $eperiod, $agentnum ) = @_;
  $self->scalar_sql("
     SELECT COUNT(*) FROM cust_pkg
     WHERE cust_pkg.custnum = cust_main.custnum
     AND ( cust_pkg.cancel IS NULL OR cust_pkg.cancel = 0 )
     AND 0 = ( SELECT COUNT(*) FROM cust_pkg
               WHERE cust_pkg.custnum = cust_main.custnum
               AND ( cust_pkg.susp IS NULL OR cust_pkg.susp = 0 )
             )
     AND cust_pkg.susp > $speriod AND cust_pkg.susp < $eperiod
  ");
}

sub in_time_period_and_agent {
  my( $self, $speriod, $eperiod, $agentnum ) = splice(@_, 0, 4);
  my $table = @_ ? shift().'.' : '';

  my $sql = "${table}_date >= $speriod AND ${table}_date < $eperiod";

  #agent selection
  $sql .= " AND agentnum = $agentnum"
    if $agentnum;

  #agent virtualization
  $sql .= ' AND '. $FS::CurrentUser::CurrentUser->agentnums_sql;

  $sql;
}

sub scalar_sql {
  my( $self, $sql ) = ( shift, shift );
  my $sth = dbh->prepare($sql) or die dbh->errstr;
  $sth->execute
    or die "Unexpected error executing statement $sql: ". $sth->errstr;
  $sth->fetchrow_arrayref->[0] || 0;
}

=back

=head1 BUGS

Documentation.

=head1 SEE ALSO

=cut

1;