Adding average loan time to stats.
[koha.git] / reports / issues_stats.pl
1 #!/usr/bin/perl
2
3 # $Id$
4
5 # Copyright 2000-2002 Katipo Communications
6 #
7 # This file is part of Koha.
8 #
9 # Koha is free software; you can redistribute it and/or modify it under the
10 # terms of the GNU General Public License as published by the Free Software
11 # Foundation; either version 2 of the License, or (at your option) any later
12 # version.
13 #
14 # Koha is distributed in the hope that it will be useful, but WITHOUT ANY
15 # WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR
16 # A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
17 #
18 # You should have received a copy of the GNU General Public License along with
19 # Koha; if not, write to the Free Software Foundation, Inc., 59 Temple Place,
20 # Suite 330, Boston, MA  02111-1307 USA
21
22 use strict;
23 use C4::Auth;
24 use CGI;
25 use C4::Context;
26 use HTML::Template;
27 use C4::Search;
28 use C4::Output;
29 use C4::Koha;
30 use C4::Interface::CGI::Output;
31 use C4::Circulation::Circ2;
32 use Date::Manip;
33
34 =head1 NAME
35
36 plugin that shows a stats on borrowers
37
38 =head1 DESCRIPTION
39
40
41 =over2
42
43 =cut
44
45 my $input = new CGI;
46 my $do_it=$input->param('do_it');
47 my $fullreportname = "reports/issues_stats.tmpl";
48 my $line = $input->param("Line");
49 my $column = $input->param("Column");
50 my @filters = $input->param("Filter");
51 my $podsp = $input->param("DisplayBy");
52 my $type = $input->param("PeriodTypeSel");
53 my $daysel = $input->param("PeriodDaySel");
54 my $monthsel = $input->param("PeriodMonthSel");
55 my $calc = $input->param("Cellvalue");
56 my $output = $input->param("output");
57 my $basename = $input->param("basename");
58 my $mime = $input->param("MIME");
59 my $del = $input->param("sep");
60 #warn "calcul : ".$calc;
61 my ($template, $borrowernumber, $cookie)
62         = get_template_and_user({template_name => $fullreportname,
63                                 query => $input,
64                                 type => "intranet",
65                                 authnotrequired => 0,
66                                 flagsrequired => {editcatalogue => 1},
67                                 debug => 1,
68                                 });
69 $template->param(do_it => $do_it);
70 if ($do_it) {
71 # Displaying results
72         my $results = calculate($line, $column, $podsp, $type, $daysel, $monthsel, $calc, \@filters);
73         if ($output eq "screen"){
74 # Printing results to screen
75                 $template->param(mainloop => $results);
76                 output_html_with_http_headers $input, $cookie, $template->output;
77                 exit(1);
78         } else {
79 # Printing to a csv file
80                 print $input->header(-type => 'application/vnd.sun.xml.calc',
81                         -attachment=>"$basename.csv",
82                         -filename=>"$basename.csv" );
83                 my $cols = @$results[0]->{loopcol};
84                 my $lines = @$results[0]->{looprow};
85                 my $sep;
86                 $sep =C4::Context->preference("delimiter");
87 # header top-right
88                 print @$results[0]->{line} ."/". @$results[0]->{column} .$sep;
89 # Other header
90                 foreach my $col ( @$cols ) {
91                         print $col->{coltitle}.$sep;
92                 }
93                 print "Total\n";
94 # Table
95                 foreach my $line ( @$lines ) {
96                         my $x = $line->{loopcell};
97                         print $line->{rowtitle}.$sep;
98                         foreach my $cell (@$x) {
99                                 print $cell->{value}.$sep;
100                         }
101                         print $line->{totalrow};
102                         print "\n";
103                 }
104 # footer
105                 print "TOTAL";
106                 $cols = @$results[0]->{loopfooter};
107                 foreach my $col ( @$cols ) {
108                         print $sep.$col->{totalcol};
109                 }
110                 print $sep.@$results[0]->{total};
111                 exit(1);
112         }
113 # Displaying choices
114 } else {
115         my $dbh = C4::Context->dbh;
116         my @values;
117         my %labels;
118         my %select;
119         my $req;
120         $req = $dbh->prepare("select distinctrow categorycode,description from categories order by description");
121         $req->execute;
122         my @select;
123         push @select,"";
124         $select{""}="";
125         while (my ($value, $desc) =$req->fetchrow) {
126                 push @select, $value;
127                 $select{$value}=$desc;
128         }
129         my $CGIBorCat=CGI::scrolling_list( -name     => 'Filter',
130                                 -id => 'Filter',
131                                 -values   => \@select,
132                                 -labels   => \%select,
133                                 -size     => 1,
134                                 -multiple => 0 );
135         
136         $req = $dbh->prepare( "select distinctrow itemtype,description from itemtypes order by description");
137         $req->execute;
138         undef @select;
139         undef %select;
140         push @select,"";
141         $select{""}="";
142         while (my ($value,$desc) =$req->fetchrow) {
143                 push @select, $value;
144                 $select{$value}=$desc;
145         }
146         my $CGIItemTypes=CGI::scrolling_list( -name     => 'Filter',
147                                 -id => 'Filter',
148                                 -values   => \@select,
149                                 -labels    => \%select,
150                                 -size     => 1,
151                                 -multiple => 0 );
152         
153         $req = $dbh->prepare("select distinctrow sort1 from borrowers where sort1 is not null order by sort1");
154         $req->execute;
155         undef @select;
156         push @select,"";
157         my $hassort1;
158         while (my ($value) =$req->fetchrow) {
159                 $hassort1 =1 if ($value);
160                 push @select, $value;
161         }
162         my $branches=getbranches();
163         my @select_branch;
164         my %select_branches;
165         push @select_branch,"";
166         $select_branches{""} = "";
167         foreach my $branch (keys %$branches) {
168                 push @select_branch, $branch;
169                 $select_branches{$branch} = $branches->{$branch}->{'branchname'};
170         }
171         my $CGIBranch=CGI::scrolling_list( -name     => 'Filter',
172                                 -id => 'Filter',
173                                 -values   => \@select_branch,
174                                 -labels   => \%select_branches,
175                                 -size     => 1,
176                                 -multiple => 0 );
177         
178         my $CGISort1=CGI::scrolling_list( -name     => 'Filter',
179                                 -id => 'Filter',
180                                 -values   => \@select,
181                                 -size     => 1,
182                                 -multiple => 0 );
183         
184         $req = $dbh->prepare("select distinctrow sort2 from borrowers where sort2 is not null order by sort2");
185         $req->execute;
186         undef @select;
187         push @select,"";
188         my $hassort2;
189         my $hglghtsort2;
190         while (my ($value) =$req->fetchrow) {
191                 $hassort2 =1 if ($value);
192                 $hglghtsort2= !($hassort1);
193                 push @select, $value;
194         }
195         my $CGISort2=CGI::scrolling_list( -name     => 'Filter',
196                                 -id => 'Filter',
197                                 -values   => \@select,
198                                 -size     => 1,
199                                 -multiple => 0 );
200         
201         my @mime = ( C4::Context->preference("MIME") );
202 #       foreach my $mime (@mime){
203 #               warn "".$mime;
204 #       }
205         
206         my $CGIextChoice=CGI::scrolling_list(
207                                 -name     => 'MIME',
208                                 -id       => 'MIME',
209                                 -values   => \@mime,
210                                 -size     => 1,
211                                 -multiple => 0 );
212         
213         my @dels = ( C4::Context->preference("delimiter") );
214         my $CGIsepChoice=CGI::scrolling_list(
215                                 -name     => 'sep',
216                                 -id       => 'sep',
217                                 -values   => \@dels,
218                                 -size     => 1,
219                                 -multiple => 0 );
220         
221         $template->param(
222                                         CGIBorCat => $CGIBorCat,
223                                         CGIItemType => $CGIItemTypes,
224                                         CGIBranch => $CGIBranch,
225                                         hassort1=> $hassort1,
226                                         hassort2=> $hassort2,
227                                         HlghtSort2 => $hglghtsort2,
228                                         CGISort1 => $CGISort1,
229                                         CGISort2 => $CGISort2,
230                                         CGIextChoice => $CGIextChoice,
231                                         CGIsepChoice => $CGIsepChoice
232                                         );
233 output_html_with_http_headers $input, $cookie, $template->output;
234 }
235
236
237
238
239 sub calculate {
240         my ($line, $column, $dsp, $type,$daysel,$monthsel ,$process, $filters) = @_;
241         my @mainloop;
242         my @loopfooter;
243         my @loopcol;
244         my @loopline;
245         my @looprow;
246         my %globalline;
247         my $grantotal =0;
248 # extract parameters
249         my $dbh = C4::Context->dbh;
250
251 # Filters
252 # Checking filters
253 #
254         my @loopfilter;
255         for (my $i=0;$i<=6;$i++) {
256                 my %cell;
257                 if ( @$filters[$i] ) {
258                         if (($i==1) and (@$filters[$i-1])) {
259                                 $cell{err} = 1 if (@$filters[$i]<@$filters[$i-1]) ;
260                         }
261                         $cell{filter} .= @$filters[$i];
262                         $cell{crit} .="Period From" if ($i==0);
263                         $cell{crit} .="Period To" if ($i==1);
264                         $cell{crit} .="Borrower Cat" if ($i==2);
265                         $cell{crit} .="Doc Type" if ($i==3);
266                         $cell{crit} .="Branch" if ($i==4);
267                         $cell{crit} .="Sort1" if ($i==5);
268                         $cell{crit} .="Sort2" if ($i==6);
269                         push @loopfilter, \%cell;
270                 }
271         }
272         push @loopfilter,{crit=>"Issue|Return ",filter=>$type};
273         push @loopfilter,{crit=>"Display by ",filter=>$dsp} if ($dsp);
274         push @loopfilter,{crit=>"Select Day ",filter=>$daysel} if ($daysel);
275         push @loopfilter,{crit=>"Select Month ",filter=>$daysel} if ($monthsel);
276         
277         
278         my @linefilter;
279 #       warn "filtres ".@filters[0];
280 #       warn "filtres ".@filters[1];
281 #       warn "filtres ".@filters[2];
282 #       warn "filtres ".@filters[3];
283         
284         $linefilter[0] = @$filters[0] if ($line =~ /datetime/ )  ;
285         $linefilter[1] = @$filters[1] if ($line =~ /datetime/ )  ;
286         $linefilter[0] = @$filters[2] if ($line =~ /category/ )  ;
287         $linefilter[0] = @$filters[3] if ($line =~ /itemtype/ )  ;
288         $linefilter[0] = @$filters[4] if ($line =~ /branch/ )  ;
289 #       $linefilter[0] = @$filters[11] if ($line =~ /sort2/ ) ;
290         $linefilter[0] = @$filters[5] if ($line =~ /sort1/ ) ;
291         $linefilter[0] = @$filters[6] if ($line =~ /sort2/ ) ;
292 #warn "filtre lignes".$linefilter[0]." ".$linefilter[1];
293
294         my @colfilter ;
295         $colfilter[0] = @$filters[0] if ($column =~ /datetime/) ;
296         $colfilter[1] = @$filters[1] if ($column =~ /datetime/) ;
297         $colfilter[0] = @$filters[2] if ($column =~ /category/) ;
298         $colfilter[0] = @$filters[3] if ($column =~ /itemtype/) ;
299         $colfilter[0] = @$filters[4] if ($column =~ /branch/ )  ;
300         $colfilter[0] = @$filters[5] if ($column =~ /sort1/  )  ;
301         $colfilter[0] = @$filters[6] if ($column =~ /sort2/  )  ;
302 #warn "filtre col ".$colfilter[0]." ".$colfilter[1];
303                                               
304 # 1st, loop rows.                             
305         my $linefield;                               
306         if (($line =~/datetime/) and ($dsp == 1)) {
307                 #Display by day
308                 $linefield .="dayname($line)";  
309         } elsif (($line=~/datetime/) and ($dsp == 2)) {
310                 #Display by Month
311                 $linefield .="monthname($line)";  
312         } elsif (($line=~/datetime/) and ($dsp == 3)) {
313                 #Display by Year
314                 $linefield .="Year($line)";
315         } elsif ($line=~/datetime/) {
316                 $linefield .= 'date_format(`datetime`,"%Y-%m-%d")';
317         } else {
318                 $linefield .= $line;
319         }  
320         
321         my $strsth;
322         $strsth .= "select distinctrow $linefield from statistics, borrowers where (statistics.borrowernumber=borrowers.borrowernumber) and $line is not null ";
323         
324         if ($line=~/datetime/) {
325                 if ($linefilter[1] and ($linefilter[0])){
326                         $strsth .= " and $line between ? and ? " ;
327                 } elsif ($linefilter[1]) {
328                                 $strsth .= " and $line < ? " ;
329                 } elsif ($linefilter[0]) {
330                         $strsth .= " and $line > ? " ;
331                 }
332                 $strsth .= " and type ='".$type."' " if $type;
333                 $strsth .= " and dayname(datetime) ='". $daysel ."' " if $daysel;
334                 $strsth .= " and monthname(datetime) ='". $monthsel ."' " if $monthsel;
335         } elsif ($linefilter[0]) {
336                 $linefilter[0] =~ s/\*/%/g;
337                 $strsth .= " and $line LIKE ? " ;
338         }
339         $strsth .=" group by $linefield";
340         $strsth .=" order by $linefield";
341 #       warn "". $strsth;
342         
343         my $sth = $dbh->prepare( $strsth );
344         if (( @linefilter ) and ($linefilter[1])){
345                 $sth->execute("'".$linefilter[0]."'","'".$linefilter[1]."'");
346         } elsif ($linefilter[0]) {
347                 $sth->execute($linefilter[0]);
348         } else {
349                 $sth->execute;
350         }
351         
352         while ( my ($celvalue) = $sth->fetchrow) {
353                 my %cell;
354                 if ($celvalue) {
355                         $cell{rowtitle} = $celvalue;
356                 } else {
357                         $cell{rowtitle} = "";
358                 }
359                 $cell{totalrow} = 0;
360                 push @loopline, \%cell;
361         }
362
363 # 2nd, loop cols.
364         my $colfield;                               
365         if (($column =~/datetime/) and ($dsp == 1)) {
366                 #Display by day
367                 $colfield .="dayname($column)";  
368         } elsif (($column=~/datetime/) and ($dsp == 2)) {
369                 #Display by Month
370                 $colfield .="monthname($column)";  
371         } elsif (($column=~/datetime/) and ($dsp == 3)) {
372                 #Display by Year
373                 $colfield .="Year($column)";
374         } elsif ($column=~/datetime/) {
375                 $colfield .='date_format(`datetime`,"%Y-%m-%d")';       
376         } else {
377                 $colfield .= $column;
378         }  
379         
380         my $strsth2;
381         $strsth2 .= "select distinctrow $colfield from statistics, borrowers where (statistics.borrowernumber=borrowers.borrowernumber) and $column is not null ";
382         
383         if ($column=~/datetime/){
384                 if (($colfilter[1]) and ($colfilter[0])){
385                         $strsth2 .= " and $column between ? and ? " ;
386                 } elsif ($colfilter[1]) {
387                         $strsth2 .= " and $column < ? " ;
388                 } elsif ($colfilter[0]) {
389                         $strsth2 .= " and $column > ? " ;
390                 }
391                 $strsth2 .= " and type ='".$type."' " if $type;
392                 $strsth2 .= " and dayname(datetime) ='". $daysel ."' " if $daysel;
393                 $strsth2 .= " and monthname(datetime) ='". $monthsel ."' " if $monthsel;
394         } elsif ($colfilter[0]) {
395                 $colfilter[0] =~ s/\*/%/g;
396                 $strsth2 .= " and $column LIKE ? " ;
397         }
398         $strsth2 .=" group by $colfield";
399         $strsth2 .=" order by $colfield";
400 #       warn "". $strsth2;
401         
402         my $sth2 = $dbh->prepare( $strsth2 );
403         if (( @colfilter ) and ($colfilter[1])){
404                 $sth2->execute("'".$colfilter[0]."'","'".$colfilter[1]."'");
405         } elsif ($colfilter[0]) {
406                 $sth2->execute($colfilter[0]);
407         } else {
408                 $sth2->execute;
409         }
410         
411
412         while (my ($celvalue) = $sth2->fetchrow) {
413                 my %cell;
414                 my %ft;
415 #               warn "coltitle :".$celvalue;
416                 $cell{coltitle} = $celvalue;
417                 $ft{totalcol} = 0;
418                 push @loopcol, \%cell;
419         }
420 #       warn "fin des titres colonnes";
421
422         my $i=0;
423         my @totalcol;
424         my $hilighted=-1;
425         
426         #Initialization of cell values.....
427         my %table;
428 #       warn "init table";
429         foreach my $row ( @loopline ) {
430                 foreach my $col ( @loopcol ) {
431 #                       warn " init table : $row->{rowtitle} / $col->{coltitle} ";
432                         $table{$row->{rowtitle}}->{$col->{coltitle}}=0;
433                 }
434                 $table{$row->{rowtitle}}->{totalrow}=0;
435         }
436
437 # preparing calculation
438         my $strcalc ;
439         if ($process ==2) {
440                 $linefield=~s/datetime/issues.returndate/;
441                 $linefield=~s/itemtype/biblioitems.itemtype/;
442                 $colfield=~s/datetime/issues.returndate/;
443                 $colfield=~s/itemtype/biblioitems.itemtype/;
444                 
445         # Processing average loanperiods
446                 $strcalc .= "SELECT $linefield, $colfield, ";
447                 $strcalc .= " DATE_SUB(date_due, INTERVAL CAST(issuingrules.issuelength AS SIGNED INTEGER) * (CAST(issues.renewals AS SIGNED INTEGER)+1) DAY) AS issuedate, returndate, COUNT(*), date_due, issues.renewals, issuelength FROM `issues`,borrowers,biblioitems LEFT JOIN items ON (biblioitems.biblioitemnumber=items.biblioitemnumber) LEFT JOIN issuingrules ON (issuingrules.branchcode=issues.branchcode AND  issuingrules.itemtype=biblioitems.itemtype AND  issuingrules.categorycode=borrowers.categorycode) WHERE issues.itemnumber=items.itemnumber AND issues.borrowernumber=borrowers.borrowernumber and returndate is not null";
448 #       
449                 @$filters[0]=~ s/\*/%/g if (@$filters[0]);
450                 $strcalc .= " AND issues.returndate > '" . @$filters[0] ."'" if ( @$filters[0] );
451                 @$filters[1]=~ s/\*/%/g if (@$filters[1]);
452                 $strcalc .= " AND issues.returndate < '" . @$filters[1] ."'" if ( @$filters[1] );
453                 @$filters[2]=~ s/\*/%/g if (@$filters[2]);
454                 $strcalc .= " AND borrowers.categorycode like '" . @$filters[2] ."'" if ( @$filters[2] );
455                 @$filters[3]=~ s/\*/%/g if (@$filters[3]);
456                 $strcalc .= " AND biblioitems.itemtype like '" . @$filters[3] ."'" if ( @$filters[3] );
457                 @$filters[4]=~ s/\*/%/g if (@$filters[4]);
458                 $strcalc .= " AND issues.branchcode like '" . @$filters[4] ."'" if ( @$filters[4] );
459                 @$filters[5]=~ s/\*/%/g if (@$filters[5]);
460                 $strcalc .= " AND borrowers.sort1 like '" . @$filters[5] ."'" if ( @$filters[5] );
461                 @$filters[6]=~ s/\*/%/g if (@$filters[6]);
462                 $strcalc .= " AND borrowers.sort2 like '" . @$filters[6] ."'" if ( @$filters[6] );
463                 $strcalc .= " AND dayname(timestamp) like '" . $daysel ."'" if ( $daysel );
464                 $strcalc .= " AND monthname(timestamp) like '" . $monthsel ."'" if ( $monthsel );
465 #               
466                 $strcalc .= " group by issuedate, returndate, $linefield, $colfield order by $linefield,$colfield";
467                 warn "SQL :". $strcalc;
468                 
469                 my $dbcalc = $dbh->prepare($strcalc);
470                 $dbcalc->execute;
471         #       warn "filling table";
472                 my $emptycol;
473                 my $issues_count=0;
474                 my $previous_row; 
475                 my $previous_col;
476                 my $loanlength; 
477                 my $err;
478                 my $weightrow;
479                 while (my  @data = $dbcalc->fetchrow) {
480                         my ($row, $col, $issuedate, $returndate, $weight)=@data;
481                         warn "filling table $row / $col / $issuedate / $returndate /$weight";
482                         $emptycol = 1 if ($col eq undef);
483                         $col = "zzEMPTY" if ($col eq undef);
484                         $row = "zzEMPTY" if ($row eq undef);
485                         warn "row :".$row." column :".$col;
486                         if (($previous_row== $row) and ($previous_col==$col)){
487                                 my @result =split /:/,DateCalc($returndate,$issuedate) ;
488 #  DateCalc returns => 0:0:WK:DD:HH:MM:SS   the weeks, days, hours, minutes,
489 #  and seconds between the two
490                                 $loanlength = $result[2]*7+$result[3];
491                                 warn "DateCalc returns :$loanlength with return ". $returndate ."issue ". $issuedate ."weight : ". $weight;
492                                 
493                                 $table{$row}->{$col}->{value}+=$weight*$loanlength;
494                                 $issues_count+=$weight;
495                         
496                         } elsif ($previous_row==$row) {
497                                 $table{$row}->{$previous_col}->{value}=$table{$row}->{$previous_col}->{value}/$issues_count;
498                                 $table{$row}->{$previous_col}->{weight}=1;
499                                 $table{$row}->{$previous_col}->{realweight}=$issues_count;
500                                 $weightrow+=$table{$row}->{$previous_col}->{weight};
501                                 $table{$row}->{totalrow}+=$table{$row}->{$previous_col}->{value};
502                                 
503                                 my @result =split /:/,DateCalc($returndate,$issuedate) ;
504 #  DateCalc returns => 0:0:WK:DD:HH:MM:SS   the weeks, days, hours, minutes,
505 #  and seconds between the two
506                                 $loanlength = $result[2]*7+$result[3];
507                                 $table{$row}->{$col}->{value}+=$weight*$loanlength;
508                                 $issues_count=$weight;
509                                 $previous_col=$col;
510                         } else {
511                                 unless (($previous_row) or ($previous_col)){
512                                         $table{$previous_row}->{$previous_col}->{value}=$table{$previous_row}->{$previous_col}->{value}/$issues_count;
513                                         $table{$previous_row}->{$previous_col}->{weight}=1;
514                                         $table{$previous_row}->{$previous_col}->{realweight}=$issues_count;
515                                         $table{$previous_row}->{totalrow}+=$table{$previous_row}->{$previous_col}->{value};
516                                         $weightrow+=$table{$row}->{$previous_col}->{weight};
517                                         $table{$previous_row}->{totalrow}=$table{$previous_row}->{totalrow}/$weightrow;
518                                 }
519                                 my @result =split /:/,DateCalc($returndate,$issuedate) ;
520 #  DateCalc returns => 0:0:WK:DD:HH:MM:SS   the weeks, days, hours, minutes,
521 #  and seconds between the two
522                                 $loanlength = $result[2]*7+$result[3];
523                                 warn "DateCalc returns :$loanlength with return ". $returndate ."issue ". $issuedate ."weight : ". $weight;
524                                 
525                                 $table{$row}->{$col}->{value}=$weight*$loanlength;
526                                 $issues_count=$weight;
527                                 $previous_row=$row;
528                                 $previous_col=$col;
529                                 $weightrow=0;
530                         }
531                 }
532                 push @loopcol,{coltitle => "NULL"} if ($emptycol);
533                 foreach my $row ( sort keys %table ) {
534                         my @loopcell;
535 #               #@loopcol ensures the order for columns is common with column titles
536 #               # and the number matches the number of columns
537                         foreach my $col ( @loopcol ) {
538                                 my $value =$table{$row}->{($col->{coltitle} eq "NULL")?"zzEMPTY":$col->{coltitle}}->{value};
539                                 push @loopcell, {value => $value  } ;
540                         }
541                         push @looprow,{ 'rowtitle' => ($row eq "zzEMPTY")?"NULL":$row,
542                                                         'loopcell' => \@loopcell,
543                                                         'hilighted' => ($hilighted >0),
544                                                         'totalrow' => $table{$row}->{totalrow}
545                                                 };
546                         $hilighted = -$hilighted;
547                 }
548 #       
549 # #     warn "footer processing";
550                 foreach my $col ( @loopcol ) {
551                         my $total=0;
552                         my $nbrow=0;
553                         foreach my $row ( @looprow ) {
554                                 $total += $table{($row->{rowtitle} eq "NULL")?"zzEMPTY":$row->{rowtitle}}->{($col->{coltitle} eq "NULL")?"zzEMPTY":$col->{coltitle}}->{value};
555                                 $nbrow++;
556 #                       warn "value added ".$table{$row->{rowtitle}}->{$col->{coltitle}}. "for line ".$row->{rowtitle};
557                         }
558 #               warn "summ for column ".$col->{coltitle}."  = ".$total;
559                         $total = $total/$nbrow if ($nbrow);
560                         push @loopfooter, {'totalcol' => $total};
561                 }
562         
563         }else {
564                 $strcalc .= "SELECT $linefield, $colfield, ";
565                 $strcalc .= "COUNT( * ) " if ($process ==1);
566                 if ($process ==3){
567                         my $rqbookcount = $dbh->prepare("SELECT count(*) FROM items");
568                         $rqbookcount->execute;
569                         my ($bookcount) = $rqbookcount->fetchrow;
570                         $strcalc .= "100*(COUNT(itemnumber))/ $bookcount " ;
571                 }
572                 $strcalc .= "FROM statistics,borrowers where (statistics.borrowernumber=borrowers.borrowernumber) ";
573         
574                 @$filters[0]=~ s/\*/%/g if (@$filters[0]);
575                 $strcalc .= " AND statistics.datetime > '" . @$filters[0] ."'" if ( @$filters[0] );
576                 @$filters[1]=~ s/\*/%/g if (@$filters[1]);
577                 $strcalc .= " AND statistics.datetime < '" . @$filters[1] ."'" if ( @$filters[1] );
578                 @$filters[2]=~ s/\*/%/g if (@$filters[2]);
579                 $strcalc .= " AND borrowers.categorycode like '" . @$filters[2] ."'" if ( @$filters[2] );
580                 @$filters[3]=~ s/\*/%/g if (@$filters[3]);
581                 $strcalc .= " AND statistics.itemtype like '" . @$filters[3] ."'" if ( @$filters[3] );
582                 @$filters[4]=~ s/\*/%/g if (@$filters[4]);
583                 $strcalc .= " AND statistics.branch like '" . @$filters[4] ."'" if ( @$filters[4] );
584                 @$filters[5]=~ s/\*/%/g if (@$filters[5]);
585                 $strcalc .= " AND borrowers.sort1 like '" . @$filters[5] ."'" if ( @$filters[5] );
586                 @$filters[6]=~ s/\*/%/g if (@$filters[6]);
587                 $strcalc .= " AND borrowers.sort2 like '" . @$filters[6] ."'" if ( @$filters[6] );
588                 $strcalc .= " AND dayname(datetime) like '" . $daysel ."'" if ( $daysel );
589                 $strcalc .= " AND monthname(datetime) like '" . $monthsel ."'" if ( $monthsel );
590                 $strcalc .= " AND statistics.type like '" . $type ."'" if ( $type );
591                 
592                 $strcalc .= " group by $linefield, $colfield order by $linefield,$colfield";
593         #       warn "". $strcalc;
594                 my $dbcalc = $dbh->prepare($strcalc);
595                 $dbcalc->execute;
596         #       warn "filling table";
597                 my $emptycol; 
598                 while (my ($row, $col, $value) = $dbcalc->fetchrow) {
599         #               warn "filling table $row / $col / $value ";
600                         $emptycol = 1 if ($col eq undef);
601                         $col = "zzEMPTY" if ($col eq undef);
602                         $row = "zzEMPTY" if ($row eq undef);
603                         
604                         $table{$row}->{$col}+=$value;
605                         $table{$row}->{totalrow}+=$value;
606                         $grantotal += $value;
607                 }
608                 push @loopcol,{coltitle => "NULL"} if ($emptycol);
609                 
610                 foreach my $row ( sort keys %table ) {
611                         my @loopcell;
612                         #@loopcol ensures the order for columns is common with column titles
613                         # and the number matches the number of columns
614                         foreach my $col ( @loopcol ) {
615                                 my $value =$table{$row}->{($col->{coltitle} eq "NULL")?"zzEMPTY":$col->{coltitle}};
616                                 push @loopcell, {value => $value  } ;
617                         }
618                         push @looprow,{ 'rowtitle' => ($row eq "zzEMPTY")?"NULL":$row,
619                                                         'loopcell' => \@loopcell,
620                                                         'hilighted' => ($hilighted >0),
621                                                         'totalrow' => $table{$row}->{totalrow}
622                                                 };
623                         $hilighted = -$hilighted;
624                 }
625                 
626         #       warn "footer processing";
627                 foreach my $col ( @loopcol ) {
628                         my $total=0;
629                         foreach my $row ( @looprow ) {
630                                 $total += $table{($row->{rowtitle} eq "NULL")?"zzEMPTY":$row->{rowtitle}}->{($col->{coltitle} eq "NULL")?"zzEMPTY":$col->{coltitle}};
631         #                       warn "value added ".$table{$row->{rowtitle}}->{$col->{coltitle}}. "for line ".$row->{rowtitle};
632                         }
633         #               warn "summ for column ".$col->{coltitle}."  = ".$total;
634                         push @loopfooter, {'totalcol' => $total};
635                 }
636         }
637                         
638
639         # the header of the table
640         $globalline{loopfilter}=\@loopfilter;
641         # the core of the table
642         $globalline{looprow} = \@looprow;
643         $globalline{loopcol} = \@loopcol;
644 #       # the foot (totals by borrower type)
645         $globalline{loopfooter} = \@loopfooter;
646         $globalline{total}= $grantotal;
647         $globalline{line} = $line;
648         $globalline{column} = $column;
649         push @mainloop,\%globalline;
650         return \@mainloop;
651 }
652
653 1;